Split string and insert to table

  • I have table follow:

    I want use procedure or function is return resurt as show

    Help me. Thanks

  • You can accomplish this using DelimitedSplit8K, note the "splitter" referenced in my signature. You would split the user column using the pipe "|" as your delimiter. Post back if you need more details.

    "I cant stress enough the importance of switching from a sequential files mindset to set-based thinking. After you make the switch, you can spend your time tuning and optimizing your queries instead of maintaining lengthy, poor-performing code."

    -- Itzik Ben-Gan 2001

  • You can provide details

  • I'm using a temp variable so you can easily copy/paste this code and run it locally. Note that you need to have delimitedsplit8K created for this to work.

    DECLARE @cap2 TABLE

    (

    id int primary key,

    ten varchar(100) not null,

    SoCV varchar(100) not null

    )

    INSERT @cap2

    VALUES (1,'user 1|user 2|user 3','93xxxyyy-abc'), (2,'user 1|user 2','555/rrr-abc/abc');

    SELECT UserName = Item, SoCV

    FROM @cap2

    CROSS APPLY dbo.DelimitedSplit8K(ten,'|');

    "I cant stress enough the importance of switching from a sequential files mindset to set-based thinking. After you make the switch, you can spend your time tuning and optimizing your queries instead of maintaining lengthy, poor-performing code."

    -- Itzik Ben-Gan 2001

  • Thanks for repply

    I've used function dbo.DelimitedSplit8K

    SET ANSI_NULLS ON

    GO

    SET QUOTED_IDENTIFIER ON

    GO

    CREATE FUNCTION dbo.DelimitedSplit8K

    --===== 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(CHARINDEX(@pDelimiter,@pString,s.N1),0)-s.N1,8000))

    FROM cteStart s

    ;

    and TSQL

    SELECT UserName=c.ten,SoCV FROM cap2 c CROSS APPLY dbo.DelimitedSplit8K(ten,'|');

    and your code

    DECLARE @cap2 TABLE

    (

    id int primary key,

    ten varchar(100) not null,

    SoCV varchar(100) not null

    )

    INSERT @cap2

    VALUES (1,'user 1|user 2|user 3','93xxxyyy-abc'), (2,'user 1|user 2','555/rrr-abc/abc');

    SELECT UserName = ten, SoCV

    FROM @cap2

    CROSS APPLY dbo.DelimitedSplit8K(ten,'|');

    it's return result

    but I want result follow

    id ten SoCV

    1 user1 93xxxyyy-abc

    2 user2 93xxxyyy-abc

    3 user3 93xxxyyy-abc

    4 user1 555/rrr-abc/abc

    5 user2 555/rrr-abc/abc

  • Quick suggestion

    😎

    DECLARE @cap2 TABLE

    (

    id int primary key,

    ten varchar(100) not null,

    SoCV varchar(100) not null

    )

    INSERT @cap2

    VALUES (1,'user 1|user 2|user 3','93xxxyyy-abc'), (2,'user 1|user 2','555/rrr-abc/abc');

    SELECT

    ROW_NUMBER() OVER (ORDER BY (SELECT NULL)) AS ID

    ,X.Item

    ,C.SoCV

    FROM @cap2 C

    CROSS APPLY dbo.DelimitedSplit8K(C.ten,'|') X;

    Output

    ID Item SoCV

    ----- -------- ----------------

    1 user 1 93xxxyyy-abc

    2 user 2 93xxxyyy-abc

    3 user 3 93xxxyyy-abc

    4 user 1 555/rrr-abc/abc

    5 user 2 555/rrr-abc/abc

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

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