Click here to monitor SSC
SQLServerCentral is supported by Red Gate Software Ltd.
 
Log in  ::  Register  ::  Not logged in
 
 
 
        
Home       Members    Calendar    Who's On


Add to briefcase

Convert Row to Column Expand / Collapse
Author
Message
Posted Wednesday, July 3, 2013 8:05 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, October 7, 2014 9:51 PM
Points: 2, Visits: 178
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 20130801 20130901
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 ShipTo Date Quantity
Item1 DC01 20130701 10
Item2 DC01 20130701 1499
Item3 DC01 20130701 37
Item1 DC01 20130801 0
Item2 DC01 20130801 1461
Item3 DC01 20130801 35
Item1 DC01 20130901 0
Item2 DC01 20130901 1142
Item3 DC01 20130901 0
Post #1470071
Posted Wednesday, July 3, 2013 8:31 AM
SSCrazy

SSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazySSCrazy

Group: General Forum Members
Last Login: Tuesday, October 21, 2014 8:55 AM
Points: 2,873, Visits: 5,185
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!"
(So many miracle inventions provided by MS to us...)

How to post your question to get the best and quick help
Post #1470089
Posted Wednesday, July 3, 2013 8:51 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: 2 days ago @ 3:29 AM
Points: 1,678, Visits: 19,554

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;



____________________________________________________

How to get the best help on a forum

http://www.sqlservercentral.com/articles/Best+Practices/61537

Never approach a goat from the front, a horse from the rear, or a fool from any direction.
Post #1470095
Posted Friday, July 5, 2013 12:21 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Tuesday, October 7, 2014 10:53 PM
Points: 3,421, Visits: 5,359
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!

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?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1470582
Posted Friday, July 5, 2013 1:33 AM


SSCommitted

SSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommittedSSCommitted

Group: General Forum Members
Last Login: 2 days ago @ 3:29 AM
Points: 1,678, Visits: 19,554

Mark - That's a pretty slick approach.


... uses your method here


____________________________________________________

How to get the best help on a forum

http://www.sqlservercentral.com/articles/Best+Practices/61537

Never approach a goat from the front, a horse from the rear, or a fool from any direction.
Post #1470608
Posted Friday, July 5, 2013 1:40 AM


Hall of Fame

Hall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of FameHall of Fame

Group: General Forum Members
Last Login: Tuesday, October 7, 2014 10:53 PM
Points: 3,421, Visits: 5,359
Mark-101232 (7/5/2013)

Mark - That's a pretty slick approach.


... uses your method here


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!

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?
Since random numbers are too important to be left to chance, let's generate some!
Learn to understand recursive CTEs by example.
Splitting strings based on patterns can be fast!
Post #1470614
Posted Friday, July 5, 2013 4:43 AM
Forum Newbie

Forum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum NewbieForum Newbie

Group: General Forum Members
Last Login: Tuesday, October 7, 2014 9:51 PM
Points: 2, Visits: 178
Thanks Mark and Dwain.

Both of your solution worked and return expected result :)

Much appreciated for your efforts
Post #1470658
« Prev Topic | Next Topic »

Add to briefcase

Permissions Expand / Collapse