Ask Help to split string by split‘;&;’

  • Can someone help me figure out how to turn this string:

    ' a=abc;&;b=1;&;c=ddd'

    into a set of results like this?

    Item    Value

    a            abc

    b             1

    c             ddd

  • DECLARE @String VARCHAR(50) = 'a=abc;&;b=1;&;c=ddd', @Delimiter CHAR(1) =';'
    SELECT
    SUBSTRING(VALUE,1,CHARINDEX('=',VALUE)-1) ITEMS,
    SUBSTRING(VALUE,CHARINDEX('=',VALUE)+1,9999) AS VALUE
    FROM STRING_SPLIT(@String,@Delimiter) where value <>'&'

    Allah bize yeter, O ne güzel vekildir.

    vedatoozer@gmail.com

  • There are several ways of achieving this, and selecting the best option depends on various factors.

    😎

    Quick questions:

    1. How are you retrieving the raw values?
    2. Are the raw values in a variable (procedural parameter etc.)?
    3. What version of SQL Server are you using?
    4. What are the sizes and cardinality?
    5. Do you intend to do this in a function, in a procedure or in a code snipped?

    Here is an example

    USE TEEST;
    GO
    SET NOCOUNT ON;
    GO
    -- Sample string does not appear correctly so it is left blank, missing the '&' sign
    DECLARE @RAWSTR VARCHAR(100) = ''; -- paste your string here
    ;WITH BASE_DATA AS
    (
    SELECT
    ROW_NUMBER() OVER (ORDER BY @@VERSION) AS RID
    ,FX.value
    -- replace the [split chars] with the '&' and semicolon combination
    FROM string_split(REPLACE(@RAWSTR,'[split chars]',CHAR(124)),CHAR(124)) AS FS
    CROSS APPLY string_split(FS.value,CHAR(61)) AS FX
    )
    ,COLUMN_DATA AS
    (
    SELECT
    CASE WHEN BD.RID % 2 = 1 THEN BD.value END AS Item
    ,CASE WHEN BD.RID % 2 = 1 THEN LEAD(BD.value,1) OVER (ORDER BY BD.RID ASC) END AS [Value]
    FROM BASE_DATA BD
    )
    SELECT
    CD.Item
    ,CD.Value
    FROM COLUMN_DATA CD
    WHERE CD.Item IS NOT NULL;
  • I'd jury-rig this one: replace the 3 chars with a single char, then use the "standard" splitter:

    ;WITH test_data AS (
    SELECT ' a=abc;&;b=1;&;c=ddd' AS string
    )
    SELECT SUBSTRING('abcdefghijklmnopqrstuvwxyz', ds.ItemNumber, 1) AS Item, ds.Item AS Value
    FROM test_data td
    CROSS APPLY (
    SELECT REPLACE(string, ';&;', CHAR(7)) AS adjusted_string
    ) AS ca1
    CROSS APPLY dbo.DelimitedSplit8K(adjusted_string, CHAR(7)) AS ds

    SQL DBA,SQL Server MVP(07, 08, 09) "It's a dog-eat-dog world, and I'm wearing Milk-Bone underwear." "Norm", on "Cheers". Also from "Cheers", from "Carla": "You need to know 3 things about Tortelli men: Tortelli men draw women like flies; Tortelli men treat women like flies; Tortelli men's brains are in their flies".

  • You might want to use the Lead version of the splitter

    😎

    CREATE FUNCTION [dbo].[DelimitedSplit8K_LEAD]
    --===== Define I/O parameters
    (@pString VARCHAR(8000), @pDelimiter CHAR(1))
    RETURNS TABLE WITH SCHEMABINDING AS
    RETURN
    --===== "Inline" CTE Driven "Tally Table” produces values from 0 up to 10,000...
    -- enough to cover VARCHAR(8000)
    WITH E1(N) AS (
    SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL
    SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL
    SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1 UNION ALL SELECT 1
    ), --10E+1 or 10 rows
    E2(N) AS (SELECT 1 FROM E1 a, E1 b), --10E+2 or 100 rows
    E4(N) AS (SELECT 1 FROM E2 a, E2 b), --10E+4 or 10,000 rows max
    cteTally(N) AS (--==== This provides the "zero base" and limits the number of rows right up front
    -- for both a performance gain and prevention of accidental "overruns"
    SELECT 0 UNION ALL
    SELECT TOP (DATALENGTH(ISNULL(@pString,1))) ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) FROM E4
    ),
    cteStart(N1) AS (--==== This returns N+1 (starting position of each "element" just once for each delimiter)
    SELECT t.N+1
    FROM cteTally t
    WHERE (SUBSTRING(@pString,t.N,1) = @pDelimiter OR t.N = 0)
    )
    --===== Do the actual split. The ISNULL/NULLIF combo handles the length for the final element when no delimiter is found.
    SELECT ItemNumber = ROW_NUMBER() OVER(ORDER BY s.N1),
    Item = SUBSTRING(@pString,s.N1,ISNULL(NULLIF((LEAD(s.N1,1,1) OVER (ORDER BY s.N1) - 1),0)-s.N1,8000))
    FROM cteStart s
    ;
    GO
  • Eirikur Eiriksson wrote:

    You might want to use the Lead version of the splitter

    I absolutely agree.  In fact, my personal copy of DelimitedSplit8K has Eirikur's wonderful performance improvement in it (and has since he wrote the article) along with credit for the excellent mod.

    I kept the name the same so that I wouldn't have to change a shedload of code.

    --Jeff Moden


    RBAR is pronounced "ree-bar" and is a "Modenism" for Row-By-Agonizing-Row.
    First step towards the paradigm shift of writing Set Based code:
    ________Stop thinking about what you want to do to a ROW... think, instead, of what you want to do to a COLUMN.

    Change is inevitable... Change for the better is not.


    Helpful Links:
    How to post code problems
    How to Post Performance Problems
    Create a Tally Function (fnTally)

Viewing 6 posts - 1 through 5 (of 5 total)

You must be logged in to reply to this topic. Login to reply