Convert Row to Column

  • Hi,

    I have some challenging requirement of getting rows to columns (i.e 20130701, 20130801, 20130901,.....)

    I am receiving Source data as shown below in Input Data section

    Header Row: Item, ShipTo, FCST01, FCST02, ..... to FCST036

    Line1: Item as Blank, ShipTo as Blank, and then all dates (ex: 20130701,20130801,....... 20150701)

    And then from line 2, actual value of the item (example Item - Item1, ShipTo - DC01, Qty - 10, .....

    and I would like to get output (as shown in Output data section).

    Can someone please help me to achieve sample output

    Input Data:

    Item ShipTo FCST01 FCST02 FCST03

    Blank Blank 20130701 2013080120130901

    Item1 DC01 10 0 0

    Item2 DC01 1499 1461 1142

    Item3 DC01 37 35 0

    While I would like to have below output having Item, ShipTo, Date and Quantity attributes

    Output Data:

    Item ShipToDate Quantity

    Item1 DC012013070110

    Item2 DC01201307011499

    Item3 DC012013070137

    Item1 DC01201308010

    Item2 DC01201308011461

    Item3 DC012013080135

    Item1 DC01201309010

    Item2 DC01201309011142

    Item3 DC01201309010

  • J.Moden "must read" article should help you:

    http://www.sqlservercentral.com/articles/Crosstab/65048/

    _____________________________________________
    "The only true wisdom is in knowing you know nothing"
    "O skol'ko nam otkrytiy chudnyh prevnosit microsofta duh!":-D
    (So many miracle inventions provided by MS to us...)

    How to post your question to get the best and quick help[/url]

  • You haven't provided enough information to answer this fully, but see if this helps

    DECLARE @t TABLE(ID INT, Item VARCHAR(10), ShipTo VARCHAR(10),FCST01 VARCHAR(10),FCST02 VARCHAR(10),FCST03 VARCHAR(10));

    INSERT INTO @t(ID, Item, ShipTo, FCST01, FCST02, FCST03)

    SELECT 1, NULL, NULL, 20130701, 20130801, 20130901 UNION ALL

    SELECT 1, 'Item1', 'DC01', 10, 0, 0 UNION ALL

    SELECT 1, 'Item2', 'DC01', 1499, 1461, 1142 UNION ALL

    SELECT 1, 'Item3', 'DC01', 37, 35, 0;

    SELECT t1.ID, t1.Item, t1.ShipTo, ca.[Date],ca.Quantity

    FROM @t t1

    INNER JOIN @t t2 ON t2.ID = t1.ID

    AND t2.Item IS NULL

    CROSS APPLY(SELECT t2.FCST01,t1.FCST01

    UNION ALL

    SELECT t2.FCST02,t1.FCST02

    UNION ALL

    SELECT t2.FCST03,t1.FCST03) ca([Date],Quantity)

    WHERE t1.Item IS NOT NULL

    ORDER BY [Date],Item;

    ____________________________________________________

    Deja View - The strange feeling that somewhere, sometime you've optimised this query before

    How to get the best help on a forum

    http://www.sqlservercentral.com/articles/Best+Practices/61537
  • What an odd requirement!

    Mark - That's a pretty slick approach.

    Using Eugene's suggestion of a Crosstab query, this is the best (or at least the least messy approach) I could come up with:

    WITH Data (ID, Item, ShipTo, FCST01, FCST02, FCST03) AS (

    SELECT 1, NULL, NULL, 20130701, 20130801, 20130901 UNION ALL

    SELECT 1, 'Item1', 'DC01', 10, 0, 0 UNION ALL

    SELECT 1, 'Item2', 'DC01', 1499, 1461, 1142 UNION ALL

    SELECT 1, 'Item3', 'DC01', 37, 35, 0)

    ,Tally(n) AS (SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3)

    SELECT c.Item

    ,c.ShipTo

    ,d.[date]

    ,Qty=MAX(d.Qty)

    FROM Data a

    CROSS APPLY Tally b

    CROSS APPLY (

    SELECT ID, Item, ShipTo, FCST01, FCST02, FCST03

    FROM Data c

    WHERE c.Item IS NOT NULL AND a.ID = c.ID

    ) c

    CROSS APPLY (

    SELECT CASE n WHEN 1 THEN a.FCST01 WHEN 2 THEN a.FCST02 WHEN 3 THEN a.FCST03 END

    ,CASE n WHEN 1 THEN c.FCST01 WHEN 2 THEN c.FCST02 WHEN 3 THEN c.FCST03 END

    ) d ([date], Qty)

    WHERE a.Item IS NULL

    GROUP BY a.ID, c.ShipTo, c.Item, d.[date]

    ORDER BY d.[date], c.Item


    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

  • Mark - That's a pretty slick approach.

    ... uses your method here[/url]

    ____________________________________________________

    Deja View - The strange feeling that somewhere, sometime you've optimised this query before

    How to get the best help on a forum

    http://www.sqlservercentral.com/articles/Best+Practices/61537
  • Mark-101232 (7/5/2013)


    Mark - That's a pretty slick approach.

    ... uses your method here[/url]

    Flattery will get you everywhere! 🙂

    But, I actually saw the UNION ALL method the first time in the discussion thread for that article (Jeff Moden suggested it there as something that would work back to SQL 2000).

    I wanted to use CROSS APPLY VALUES here but alas was unable to because this is the SQL 2005 forum.


    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

  • Thanks Mark and Dwain.

    Both of your solution worked and return expected result 🙂

    Much appreciated for your efforts

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

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