Split column values to multiple rows

  • Hi,

    My requirement is to split columns [Owner],[PersonAttending],[Type] into multiple rows if more than one value is there for the column. Attached is the code snippet. Please help!

    Thanks,

    PSB

    CREATE TABLE #SplitColumnsToRows
    (
    ID INT,
    Title nvarchar(1000),
    [Owner] nvarchar(1000),
    [PersonAttending] nvarchar(1000),
    [Type] nvarchar(500)

    )


    Insert INTO #SplitColumnsToRows ( ID,Title,[Owner],[PersonAttending],[Type])

    SELECT 1,'Title 1','Neil;Jennifer','Ronaldo;Ashok','End to End;BIN' UNION ALL
    SELECT 2,'Title 2','Mohan;Sankara','Lisa;Holand','Support;BIN'

    SELECT * FROM #SplitColumnsToRows

    -- Desired output

    SELECT 1 AS ID,'Title 1' AS Title,'Neil' AS [Owner],'Ronaldo' AS [PersonAttending],'End to End' AS [Type] UNION ALL

    SELECT 1 AS ID,'Title 1' AS Title,'Jennifer' AS [Owner],'Ronaldo' AS [PersonAttending],'End to End' AS [Type] UNION ALL



    SELECT 1 AS ID,'Title 1' AS Title,'Neil' AS [Owner],'Ashok' AS [PersonAttending],'BIN' AS [Type] UNION ALL

    SELECT 1 AS ID,'Title 1' AS Title,'Jennifer' AS [Owner],'Ashok' AS [PersonAttending],'BIN' AS [Type] UNION ALL


    SELECT 2 AS ID,'Title 2' AS Title,'Mohan' AS [Owner],'Lisa' AS [PersonAttending],'Support' AS [Type] UNION ALL

    SELECT 2 AS ID,'Title 2' AS Title,'Sankara' AS [Owner],'Lisa' AS [PersonAttending],'Support' AS [Type] UNION ALL


    SELECT 2 AS ID,'Title 2' AS Title,'Mohan' AS [Owner],'Holand' AS [PersonAttending],'BIN' AS [Type] UNION ALL

    SELECT 2 AS ID,'Title 2' AS Title,'Sankara' AS [Owner],'Holand' AS [PersonAttending],'BIN' AS [Type]


    DROP TABLE #SplitColumnsToRows

     

     

  • It seems the data is ordinally JOIN'ed between PersonAttending and Type and CROSS JOIN'ed between PersonAttending and Owner.  To do the ordinal splitting this uses dbo.DelimitedSplit8K_LEAD.  Ordinal splitters and specifically dbo.DelimitedSplit8K_LEAD could be read about here and here.

    ;with
    id_split_person_cte(id, ItemNumber, [PersonAttending]) as (
    select id, splt_person.ItemNumber, splt_person.Item
    from #SplitColumnsToRows sctr
    cross apply dbo.DelimitedSplit8K_LEAD(sctr.[PersonAttending], ';') splt_person),
    id_split_type_cte(id, ItemNumber, [Type]) as (
    select id, splt_type.ItemNumber, splt_type.Item
    from #SplitColumnsToRows sctr
    cross apply dbo.DelimitedSplit8K_LEAD(sctr.[Type], ';') splt_type),
    id_person_type_cte(id, ItemNumber, [PersonAttending], [Type]) as (
    select p.*, t.[Type]
    from id_split_person_cte p
    join id_split_type_cte t on p.id=t.id
    and p.ItemNumber=t.ItemNumber)
    select sctr.ID, sctr.Title, splt_owner.Item, pt.*
    from #SplitColumnsToRows sctr
    join id_person_type_cte pt on sctr.ID=pt.id
    cross apply dbo.DelimitedSplit8K_LEAD(sctr.[Owner], ';') splt_owner
    order by sctr.id, pt.ItemNumber;

    The code for dbo.DelimitedSplit8K_LEAD

    CREATE FUNCTION [dbo].[DelimitedSplit8K_LEAD]
    --===== Define I/O parameters
    (@pString VARCHAR(8000), @pDelimiter CHAR(1))
    RETURNS TABLE WITH SCHEMABINDING AS
    RETURN
    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
    ;

    Aus dem Paradies, das Cantor uns geschaffen, soll uns niemand vertreiben können

  • For ID 711 the output is not correct. Atta

    CREATE TABLE #SplitColumnsToRows
    (
    ID INT,
    Title nvarchar(1000),
    [Owner] nvarchar(1000),
    [PersonAttending] nvarchar(1000),
    [Type] nvarchar(500)

    )


    Insert INTO #SplitColumnsToRows ( ID,Title,[Owner],[PersonAttending],[Type])

    SELECT 711,'Training requirements','','Weiying Song;Muhammad Ismail Aftab;Saravana Kumar Rao;Rasha Kulari;Divya MacMilan;LaSonji Turner;Madalina Elena Holand','Communication;E2E' UNION ALL
    SELECT 1,'Title 1','Neil Spencer;Jennifer Hudson','Ronaldo Mac;Ashok Nerula','End to End;BIN' UNION ALL
    SELECT 2,'Title 2','Mohan Rao;Sankara Rao','Lisa Turner;Holand Mac','Support;BIN'


    SELECT * FROM #SplitColumnsToRows
    --'Weiying Song;Muhammad Ismail Aftab;Saravana Kumar Rao;Rasha Kulari;Divya MacMilan;LaSonji Turner;Madalina Elena Holand'

    ;with
    id_split_person_cte(id, ItemNumber, [PersonAttending]) as (
    select id, splt_person.ItemNumber, splt_person.Item
    from #SplitColumnsToRows sctr
    cross apply ODRM.dbo.DelimitedSplit8K_LEAD(sctr.[PersonAttending], ';') splt_person),
    id_split_type_cte(id, ItemNumber, [Type]) as (
    select id, splt_type.ItemNumber, splt_type.Item
    from #SplitColumnsToRows sctr
    cross apply ODRM.dbo.DelimitedSplit8K_LEAD(sctr.[Type], ';') splt_type),
    id_person_type_cte(id, ItemNumber, [PersonAttending], [Type]) as (
    select p.*, t.[Type]
    from id_split_person_cte p
    join id_split_type_cte t on p.id=t.id
    and p.ItemNumber=t.ItemNumber)
    select sctr.ID, sctr.Title, splt_owner.Item, pt.*
    from #SplitColumnsToRows sctr
    join id_person_type_cte pt on sctr.ID=pt.id
    cross apply ODRM.dbo.DelimitedSplit8K_LEAD(sctr.[Owner], ';') splt_owner
    order by sctr.id, pt.ItemNumber;

    --Desired output

    SELECT 711 AS ID,'Training requirements' AS Title,'' AS [Owner],'Weiying Song' AS [PersonAttending],'Communication' AS [Type] UNION ALL

    SELECT 711 AS ID,'Training requirements' AS Title,'' AS [Owner],'Muhammad Ismail Aftab' AS [PersonAttending],'Communication' AS [Type] UNION ALL

    SELECT 711 AS ID,'Training requirements' AS Title,'' AS [Owner],'Saravana Kumar Rao' AS [PersonAttending],'Communication' AS [Type] UNION ALL

    SELECT 711 AS ID,'Training requirements' AS Title,'' AS [Owner],'Rasha Kulari' AS [PersonAttending],'Communication' AS [Type] UNION ALL

    SELECT 711 AS ID,'Training requirements' AS Title,'' AS [Owner],'Divya MacMilan' AS [PersonAttending],'Communication' AS [Type] UNION ALL

    SELECT 711 AS ID,'Training requirements' AS Title,'' AS [Owner],'LaSonji Turner' AS [PersonAttending],'Communication' AS [Type] UNION ALL

    SELECT 711 AS ID,'Training requirements' AS Title,'' AS [Owner],'Madalina Elena Holand' AS [PersonAttending],'Communication' AS [Type] UNION ALL


    SELECT 711 AS ID,'Training requirements' AS Title,'' AS [Owner],'Weiying Song' AS [PersonAttending],'E2E' AS [Type] UNION ALL

    SELECT 711 AS ID,'Training requirements' AS Title,'' AS [Owner],'Muhammad Ismail Aftab' AS [PersonAttending],'E2E' AS [Type] UNION ALL

    SELECT 711 AS ID,'Training requirements' AS Title,'' AS [Owner],'Saravana Kumar Rao' AS [PersonAttending],'E2E' AS [Type] UNION ALL

    SELECT 711 AS ID,'Training requirements' AS Title,'' AS [Owner],'Rasha Kulari' AS [PersonAttending],'E2E' AS [Type] UNION ALL

    SELECT 711 AS ID,'Training requirements' AS Title,'' AS [Owner],'Divya MacMilan' AS [PersonAttending],'E2E' AS [Type] UNION ALL

    SELECT 711 AS ID,'Training requirements' AS Title,'' AS [Owner],'LaSonji Turner' AS [PersonAttending],'E2E' AS [Type] UNION ALL

    SELECT 711 AS ID,'Training requirements' AS Title,'' AS [Owner],'Madalina Elena Holand' AS [PersonAttending],'E2E' AS [Type]




    DROP TABLE #SplitColumnsToRows

    ched is the code.

  • Got any more examples?  It appears there are 2 sets of rules for the 2 different scenarios:

    Scenario 1) Owner='' -----> (if [Owner]='' then PersonAttending and Type columns are CROSS JOIN'ed)

    Scenario 2) Owner<>'' ---> (if [Owner]<>'' then PersonAttending and Type columns are ordinally JOIN'ed)

    Does this seem correct?

    Aus dem Paradies, das Cantor uns geschaffen, soll uns niemand vertreiben können

  • ;with
    id_split_person_cte(id, [Owner], ItemNumber, [PersonAttending]) as (
    select sctr.id, sctr.[Owner], splt_person.ItemNumber, splt_person.Item
    from #SplitColumnsToRows sctr
    cross apply dbo.DelimitedSplit8K_LEAD(sctr.[PersonAttending], ';') splt_person),
    id_split_type_cte(id, [Owner], ItemNumber, [Type]) as (
    select sctr.id, sctr.[Owner], splt_type.ItemNumber, splt_type.Item
    from #SplitColumnsToRows sctr
    cross apply dbo.DelimitedSplit8K_LEAD(sctr.[Type], ';') splt_type),
    id_person_type_ne_cte(id, ItemNumber, [PersonAttending], [Type]) as (
    select p.id, p.ItemNumber, p.[PersonAttending], t.[Type]
    from id_split_person_cte p
    join id_split_type_cte t on p.id=t.id
    and p.ItemNumber=t.ItemNumber
    where p.[Owner]<>''
    and t.[Owner]<>''),
    id_person_type_eq_cte(id, ItemNumber, [PersonAttending], [Type]) as (
    select p.id, p.ItemNumber, p.[PersonAttending], t.[Type]
    from id_split_person_cte p
    join id_split_type_cte t on p.id=t.id
    where p.[Owner]=''
    and t.[Owner]='')
    select sctr.ID, sctr.Title, splt_owner.Item, pt.*
    from #SplitColumnsToRows sctr
    join id_person_type_ne_cte pt on sctr.ID=pt.id
    cross apply dbo.DelimitedSplit8K_LEAD(sctr.[Owner], ';') splt_owner
    union all
    select sctr.ID, sctr.Title, splt_owner.Item, pt.*
    from #SplitColumnsToRows sctr
    join id_person_type_eq_cte pt on sctr.ID=pt.id
    cross apply dbo.DelimitedSplit8K_LEAD(sctr.[Owner], ';') splt_owner
    order by sctr.id, pt.[Type], pt.ItemNumber;

    • This reply was modified 2 years, 10 months ago by  Steve Collins.

    Aus dem Paradies, das Cantor uns geschaffen, soll uns niemand vertreiben können

  • Hi,

    Thanks for getting back. There is no connection between [Owner],[PersonAttending],[Type] columns.

    1. While Owner column can be blank and [PersonAttending],[Type] still have values.
    2. Owner (different people than [PersonAttending]) <> [PersonAttending] and [Type] may or maynot have values
    3. Owner could be a subset of [PersonAttending] and [Type] may or maynot have values
    4. Owner have (single or multiple names) while PersonAttending is blank and [Type] may or maynot have values

    Thanks,

    PSB

  • PSB wrote:

    Hi,

    Thanks for getting back. There is no connection between [Owner],[PersonAttending],[Type] columns.

    1. While Owner column can be blank and [PersonAttending],[Type] still have values.
    2. Owner (different people than [PersonAttending]) <> [PersonAttending] and [Type] may or maynot have values
    3. Owner could be a subset of [PersonAttending] and [Type] may or maynot have values
    4. Owner have (single or multiple names) while PersonAttending is blank and [Type] may or maynot have values

    Thanks,

    PSB

    This doesn't tell us the rules for how to join the data and provide the results.  Without that - it isn't going to be possible to provide a solution.

     

    Jeffrey Williams
    “We are all faced with a series of great opportunities brilliantly disguised as impossible situations.”

    ― Charles R. Swindoll

    How to post questions to get better answers faster
    Managing Transaction Logs

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

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