SQL Clone
SQLServerCentral is supported by Redgate
 
Log in  ::  Register  ::  Not logged in
 
 
 


Convert Row to Column


Convert Row to Column

Author
Message
shahmihir000
shahmihir000
Forum Newbie
Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)

Group: General Forum Members
Points: 2 Visits: 210
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
Eugene Elutin
Eugene Elutin
SSChampion
SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)SSChampion (12K reputation)

Group: General Forum Members
Points: 12644 Visits: 5478
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
Mark Cowne
Mark Cowne
SSCertifiable
SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)

Group: General Forum Members
Points: 6535 Visits: 25572
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




dwain.c
dwain.c
SSCoach
SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)

Group: General Forum Members
Points: 18063 Visits: 6431
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!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
Mark Cowne
Mark Cowne
SSCertifiable
SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)SSCertifiable (6.5K reputation)

Group: General Forum Members
Points: 6535 Visits: 25572

Mark - That's a pretty slick approach.


... uses your method here

____________________________________________________

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




dwain.c
dwain.c
SSCoach
SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)SSCoach (18K reputation)

Group: General Forum Members
Points: 18063 Visits: 6431
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!
My temporal SQL musings: Calendar Tables, an Easter SQL, Time Slots and Self-maintaining, Contiguous Effective Dates in Temporal Tables
shahmihir000
shahmihir000
Forum Newbie
Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)Forum Newbie (2 reputation)

Group: General Forum Members
Points: 2 Visits: 210
Thanks Mark and Dwain.

Both of your solution worked and return expected result Smile

Much appreciated for your efforts
Go


Permissions

You can't post new topics.
You can't post topic replies.
You can't post new polls.
You can't post replies to polls.
You can't edit your own topics.
You can't delete your own topics.
You can't edit other topics.
You can't delete other topics.
You can't edit your own posts.
You can't edit other posts.
You can't delete your own posts.
You can't delete other posts.
You can't post events.
You can't edit your own events.
You can't edit other events.
You can't delete your own events.
You can't delete other events.
You can't send private messages.
You can't send emails.
You can read topics.
You can't vote in polls.
You can't upload attachments.
You can download attachments.
You can't post HTML code.
You can't edit HTML code.
You can't post IFCode.
You can't post JavaScript.
You can post emoticons.
You can't post or upload images.

Select a forum

































































































































































SQLServerCentral


Search