Splitting column values iin multiple columns and assigning it to a row

  • How do I write a query using the split function for the following requirement

    I have a table in the following way

    Identity Name Col1 Col2 Col3

    1 Test1 1,2,3 200,300,400 3,4,6

    2 Test2 3,4,5 300,455,600 2,3,8

    I want an output in the following format

    Identity Name Col1 Col2 Col3

    1 Test1 1 200 3

    1 Test1 2 300 4

    1 Test1 3 400 6

    2 Test2 3 300 2

    2 Test2 4 455 3

    2 Test2 5 600 8

    If you see the data, first element in col1 is matched to first element in col2 and 3 after splitting the string.

  • I hope that you're trying to normalize your data permanently because this will give you headaches.

    To split data you could use the DelimitedSplit8k. Check the article as it's really interesting.

    http://www.sqlservercentral.com/articles/Tally+Table/72993/

    WITH SampleData([Identity], Name, Col1, Col2, Col3) AS(

    SELECT 1, 'Test1', '1,2,3', '200,300,400', '3,4,6' UNION ALL

    SELECT 2, 'Test2', '3,4,5', '300,455,600', '2,3,8'

    )

    SELECT [Identity],

    Name,

    Split1.Item AS Col1,

    Split2.Item AS Col2,

    Split3.Item AS Col3

    FROM SampleData

    CROSS APPLY dbo.DelimitedSplit8K( Col1, ',') Split1

    CROSS APPLY dbo.DelimitedSplit8K( Col2, ',') Split2

    CROSS APPLY dbo.DelimitedSplit8K( Col3, ',') Split3

    WHERE Split1.ItemNumber = Split2.ItemNumber

    AND Split1.ItemNumber = Split3.ItemNumber

    ORDER BY [Identity], Split1.ItemNumber

    Luis C.
    General Disclaimer:
    Are you seriously taking the advice and code from someone from the internet without testing it? Do you at least understand it? Or can it easily kill your server?

    How to post data/code on a forum to get the best help: Option 1 / Option 2
  • Here's another way to do the same thing but using a single CROSS APPLY of DelimitedSplit8K.

    WITH SampleData ([Identity], Name, Col1, Col2, Col3) AS

    (

    SELECT 1,'Test1','1,2,3','200,300,400','3,4,6'

    UNION ALL SELECT 2,'Test2','3,4,5','300,455,600','2,3,8'

    UNION ALL SELECT 3,'Test3','30,40,50,60','3000,4550,6000,7000','20,30,80,90'

    )

    SELECT [Identity], Name--, Item, ItemNumber, rn

    ,Col1=MAX(CASE (ItemNumber+rn-1)/rn WHEN 1 THEN Item END)

    ,Col2=MAX(CASE (ItemNumber+rn-1)/rn WHEN 2 THEN Item END)

    ,Col3=MAX(CASE (ItemNumber+rn-1)/rn WHEN 3 THEN Item END)

    FROM

    (

    SELECT [Identity], Name, Item, ItemNumber

    ,rn=MAX(ItemNumber) OVER (PARTITION BY [Identity], Name)/3

    FROM SampleData a

    CROSS APPLY (SELECT Col1+','+Col2+','+Col3) b(Col)

    CROSS APPLY dbo.DelimitedSplit8K(Col, ',') c

    ) a

    GROUP BY [Identity], Name, (ItemNumber)%rn

    ORDER BY [Identity], Name, Col1;

    I do wonder what would happen to Luis's and my solutions if one of the lists in any of the columns was short a value. 😛 Not sure if that's a case you need to consider.

    Well actually, I do know what would happen in my case (the results would get garbled in different ways depending on which column was missing the item). Didn't test Luis's case although I suspect it would simply be missing some rows.


    My mantra: No loops! No CURSORs! No RBAR! Hoo-uh![/I]

    My thought question: Have you ever been told that your query runs too fast?

    My advice:
    INDEXing a poor-performing query is like putting sugar on cat food. Yeah, it probably tastes better but are you sure you want to eat it?
    The path of least resistance can be a slippery slope. Take care that fixing your fixes of fixes doesn't snowball and end up costing you more than fixing the root cause would have in the first place.

    Need to UNPIVOT? Why not CROSS APPLY VALUES instead?[/url]
    Since random numbers are too important to be left to chance, let's generate some![/url]
    Learn to understand recursive CTEs by example.[/url]
    [url url=http://www.sqlservercentral.com/articles/St

Viewing 3 posts - 1 through 2 (of 2 total)

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