January 24, 2014 at 3:18 pm
[font="Courier New"]--Need some help reformatting data in a PIVOT Table or find a better way to display.
--ORDERDETAIL TABLE
SKUO QTYO ORDERIDO
KUM 1 12345
KUS 2 12345
SUK 1 12345
KHN 4 12345
DRE 1 12345
HGF 2 12345
FDE 1 12345
CDS 1 12345
GYT 1 12345
POI 3 12345
LKH 2 12345
TTT 4 12345
JHG 8 12345
YUI 2 12345
WQE 1 12345
PMN 1 12345
BVC 1 12345
ABD 1 12345
CDE 1 89001
TUI 2 89001
JHU 1 89001
LKO 2 76543
Number of SKU's in order could be over 1000.
Looking to change my current pivot table to allow an unlimited number of SKU's and add QTY.
Data I am looking to get. MAX of 15 SKUS Per line.
ORDERID SKU1 QTY1 SKU2 QTY2 SKU3 QTY3 SKU4 QTY4 SKU5 QTY5 SKU6 QTY6 SKU7 QTY7 SKU8 QTY8 SKU9 QTY9 SKU10 QTY10 SKU11 QTY11 SKU12 QTY12 SKU13 QTY13 SKU14 QTY14 SKU15 QTY15
12345 KUM 1 KUS 2 SUK 1 KHN 4 DRE 1 HGF 2 FDE 1 CDS 1 GYT 1 POI 3 LKH 2 TTT 4 JHG 8 YUI 2 WQE 1
12345 PMN 1 BVC 1 ABD 1 NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL
89001 CDE 1 TUI 2 JHU 1 NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL
76543 LKO 2 NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL
CURRENT PIVOT ONLY GOES TO 150 - BELOW
SELECT PKGCUSTOM4, [1] AS [SKU1], [2] AS [SKU2], [3] AS [SKU3], [4] AS [SKU4], [5] AS [SKU5], [6] AS [SKU6], [7] AS [SKU7], [8] AS [SKU8], [9] AS [SKU9], [10] AS [SKU10],
[11] AS [SKU11], [12] AS [SKU12], [13] AS [SKU13], [14] AS [SKU14], [15] AS [SKU15], [16] AS [SKU16], [17] AS [SKU17], [18] AS [SKU18], [19] AS [SKU19],
[20] AS [SKU20], [21] AS [SKU21], [22] AS [SKU22], [23] AS [SKU23], [24] AS [SKU24], [25] AS [SKU25], [26] AS [SKU26], [27] AS [SKU27], [28] AS [SKU28],
[29] AS [SKU29], [30] AS [SKU30], [31] AS [SKU31], [32] AS [SKU32], [33] AS [SKU33], [34] AS [SKU34], [35] AS [SKU35], [36] AS [SKU36], [37] AS [SKU37],
[38] AS [SKU38], [39] AS [SKU39], [40] AS [SKU40], [41] AS [SKU41], [42] AS [SKU42], [43] AS [SKU43], [44] AS [SKU44], [45] AS [SKU45], [46] AS [SKU46],
[47] AS [SKU47], [48] AS [SKU48], [49] AS [SKU49], [50] AS [SKU50], [51] AS [SKU51], [52] AS [SKU52], [53] AS [SKU53], [54] AS [SKU54], [55] AS [SKU55],
[56] AS [SKU56], [57] AS [SKU57], [58] AS [SKU58], [59] AS [SKU59], [60] AS [SKU60], [61] AS [SKU61], [62] AS [SKU62], [63] AS [SKU63], [64] AS [SKU64],
[65] AS [SKU65], [66] AS [SKU66], [67] AS [SKU67], [68] AS [SKU68], [69] AS [SKU69], [70] AS [SKU70], [71] AS [SKU71], [72] AS [SKU72], [73] AS [SKU73],
[74] AS [SKU74], [75] AS [SKU75], [76] AS [SKU76], [77] AS [SKU77], [78] AS [SKU78], [79] AS [SKU79], [80] AS [SKU80], [81] AS [SKU81], [82] AS [SKU82],
[83] AS [SKU83], [84] AS [SKU84], [85] AS [SKU85], [86] AS [SKU86], [87] AS [SKU87], [88] AS [SKU88], [89] AS [SKU89], [90] AS [SKU90], [91] AS [SKU91],
[92] AS [SKU92], [93] AS [SKU93], [94] AS [SKU94], [95] AS [SKU95], [96] AS [SKU96], [97] AS [SKU97], [98] AS [SKU98], [99] AS [SKU99], [100] AS [SKU100],
[101] AS [SKU101], [102] AS [SKU102], [103] AS [SKU103], [104] AS [SKU104], [105] AS [SKU105], [106] AS [SKU106], [107] AS [SKU107], [108] AS [SKU108],
[109] AS [SKU109], [110] AS [SKU110], [111] AS [SKU111], [112] AS [SKU112], [113] AS [SKU113], [114] AS [SKU114], [115] AS [SKU115], [116] AS [SKU116],
[117] AS [SKU117], [118] AS [SKU118], [119] AS [SKU119], [120] AS [SKU120], [121] AS [SKU121], [122] AS [SKU122], [123] AS [SKU123], [124] AS [SKU124],
[125] AS [SKU125], [126] AS [SKU126], [127] AS [SKU127], [128] AS [SKU128], [129] AS [SKU129], [130] AS [SKU130], [131] *** [SKU131], [132] AS [SKU132],
[133] AS [SKU133], [134] AS [SKU134], [135] AS [SKU135], [136] AS [SKU136], [137] AS [SKU137], [138] AS [SKU138], [139] AS [SKU139], [140] AS [SKU140],
[141] AS [SKU141], [142] AS [SKU142], [143] AS [SKU143], [144] AS [SKU144], [145] AS [SKU145], [146] AS [SKU146], [147] AS [SKU147], [148] AS [SKU148],
[149] AS [SKU149], [150] AS [SKU150]
FROM (SELECT DISTINCT PKGCUSTOM4, PKGCUSTOM1, ROW_NUMBER() OVER (PARTITION BY PKGCUSTOM4
ORDER BY PKGCUSTOM4) rownum
FROM dbo.COMMERCEHUB
WHERE MOVED IS NULL) t PIVOT (MAX(PKGCUSTOM1) FOR rownum IN ([1], [2], [3], [4], [5], [6], [7], [8], [9], [10], [11], [12], [13], [14], [15], [16], [17], [18], [19], [20], [21], [22], [23],
[24], [25], [26], [27], [28], [29], [30], [31], [32], [33], [34], [35], [36], [37], [38], [39], [40], [41], [42], [43], [44], [45], [46], [47], [48], [49], [50], [51], [52], [53], [54], [55], [56], [57], [58],
[59], [60], [61], [62], [63], [64], [65], [66], [67], [68], [69], [70], [71], [72], [73], [74], [75], [76], [77], [78], [79], [80], [81], [82], [83], [84], [85], [86], [87], [88], [89], [90], [91], [92], [93],
[94], [95], [96], [97], [98], [99], [100], [101], [102], [103], [104], [105], [106], [107], [108], [109], [110], [111], [112], [113], [114], [115], [116], [117], [118], [119], [120], [121], [122],
[123], [124], [125], [126], [127], [128], [129], [130], [131], [132], [133], [134], [135], [136], [137], [138], [139], [140], [141], [142], [143], [144], [145], [146], [147], [148], [149], [150])) p[/font]
For more flexible code layout functionality from within SQL Server Management Studio or Visual Studio, download Red Gate SQL Prompt.
January 24, 2014 at 7:16 pm
Can you use SSRS, or are you doing this in a query only?
January 24, 2014 at 8:09 pm
Its a query only from classic asp code.
January 24, 2014 at 11:53 pm
You might want to read Dwain Camps' article on Creating Dynamic Crosstabs... that might give you some ideas.
January 25, 2014 at 3:13 pm
wit_jp2001 (1/24/2014)
[font="Courier New"]--Need some help reformatting data in a PIVOT Table or find a better way to display.--ORDERDETAIL TABLE
SKUO QTYO ORDERIDOKUM 1 12345
KUS 2 12345
SUK 1 12345
KHN 4 12345
DRE 1 12345
HGF 2 12345
FDE 1 12345
CDS 1 12345
GYT 1 12345
POI 3 12345
LKH 2 12345
TTT 4 12345
JHG 8 12345
YUI 2 12345
WQE 1 12345
PMN 1 12345
BVC 1 12345
ABD 1 12345
CDE 1 89001
TUI 2 89001
JHU 1 89001
LKO 2 76543
Number
of SKU's in order could be over 1000.Looking to change my current pivot table to allow an unlimited number of SKU'
s and add QTY.Data I am looking
to get. MAX of 15 SKUS Per line.ORDERID SKU1 QTY1 SKU2 QTY2 SKU3 QTY3 SKU4 QTY4 SKU5 QTY5 SKU6 QTY6 SKU7 QTY7 SKU8 QTY8 SKU9 QTY9 SKU10 QTY10 SKU11 QTY11 SKU12 QTY12 SKU13 QTY13 SKU14 QTY14 SKU15 QTY15
12345 KUM 1 KUS 2 SUK 1 KHN 4 DRE 1 HGF 2 FDE 1 CDS 1 GYT 1 POI 3 LKH 2 TTT 4 JHG 8 YUI 2 WQE 1
12345 PMN 1 BVC 1 ABD 1
NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL89001 CDE 1 TUI 2 JHU 1 NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL76543 LKO 2 NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULL NULLCURRENT PIVOT ONLY GOES TO 150 - BELOWSELECT PKGCUSTOM4, [1] AS [SKU1], [2] AS [SKU2], [3] AS [SKU3], [4] AS [SKU4], [5] AS [SKU5], [6] AS [SKU6], [7] AS [SKU7], [8] AS [SKU8], [9] AS [SKU9], [10] AS [SKU10],[11] AS [SKU11], [12] AS [SKU12], [13] AS [SKU13], [14] AS [SKU14], [15] AS [SKU15], [16] AS [SKU16], [17] AS [SKU17], [18] AS [SKU18], [19] AS [SKU19],
[20] AS [SKU20], [21] AS [SKU21], [22] AS [SKU22], [23] AS [SKU23], [24] AS [SKU24], [25] AS [SKU25], [26] AS [SKU26], [27] AS [SKU27], [28] AS [SKU28],
[29] AS [SKU29], [30] AS [SKU30], [31] AS [SKU31], [32] AS [SKU32], [33] AS [SKU33], [34] AS [SKU34], [35] AS [SKU35], [36] AS [SKU36], [37] AS [SKU37],
[38] AS [SKU38], [39] AS [SKU39], [40] AS [SKU40], [41] AS [SKU41], [42] AS [SKU42], [43] AS [SKU43], [44] AS [SKU44], [45] AS [SKU45], [46] AS [SKU46],
[47] AS [SKU47], [48] AS [SKU48], [49] AS [SKU49], [50] AS [SKU50], [51] AS [SKU51], [52] AS [SKU52], [53] AS [SKU53], [54] AS [SKU54], [55] AS [SKU55],
[56] AS [SKU56], [57] AS [SKU57], [58] AS [SKU58], [59] AS [SKU59], [60] AS [SKU60], [61] AS [SKU61], [62] AS [SKU62], [63] AS [SKU63], [64] AS [SKU64],
[65] AS [SKU65], [66] AS [SKU66], [67] AS [SKU67], [68] AS [SKU68], [69] AS [SKU69], [70] AS [SKU70], [71] AS [SKU71], [72] AS [SKU72], [73] AS [SKU73],
[74] AS [SKU74], [75] AS [SKU75], [76] AS [SKU76], [77] AS [SKU77], [78] AS [SKU78], [79] AS [SKU79], [80] AS [SKU80], [81] AS [SKU81], [82] AS [SKU82],
[83] AS [SKU83], [84] AS [SKU84], [85] AS [SKU85], [86] AS [SKU86], [87] AS [SKU87], [88] AS [SKU88], [89] AS [SKU89], [90] AS [SKU90], [91] AS [SKU91],
[92] AS [SKU92], [93] AS [SKU93], [94] AS [SKU94], [95] AS [SKU95], [96] AS [SKU96], [97] AS [SKU97], [98] AS [SKU98], [99] AS [SKU99], [100] AS [SKU100],
[101] AS [SKU101], [102] AS [SKU102], [103] AS [SKU103], [104] AS [SKU104], [105] AS [SKU105], [106] AS [SKU106], [107] AS [SKU107], [108] AS [SKU108],
[109] AS [SKU109], [110] AS [SKU110], [111] AS [SKU111], [112] AS [SKU112], [113] AS [SKU113], [114] AS [SKU114], [115] AS [SKU115], [116] AS [SKU116],
[117] AS [SKU117], [118] AS [SKU118], [119] AS [SKU119], [120] AS [SKU120], [121] AS [SKU121], [122] AS [SKU122], [123] AS [SKU123], [124] AS [SKU124],
[125] AS [SKU125], [126] AS [SKU126], [127] AS [SKU127], [128] AS [SKU128], [129] AS [SKU129], [130] AS [SKU130], [131] *** [SKU131], [132] AS [SKU132],
[133] AS [SKU133], [134] AS [SKU134], [135] AS [SKU135], [136] AS [SKU136], [137] AS [SKU137], [138] AS [SKU138], [139] AS [SKU139], [140] AS [SKU140],
[141] AS [SKU141], [142] AS [SKU142], [143] AS [SKU143], [144] AS [SKU144], [145] AS [SKU145], [146] AS [SKU146], [147] AS [SKU147], [148] AS [SKU148],
[149] AS [SKU149], [150] AS [SKU150]FROM (SELECT DISTINCT PKGCUSTOM4, PKGCUSTOM1, ROW_NUMBER() OVER (PARTITION BY PKGCUSTOM4
ORDER BY PKGCUSTOM4) rownumFROM dbo.COMMERCEHUBWHERE MOVED IS NULL) t PIVOT (MAX(PKGCUSTOM1) FOR rownum IN ([1], [2], [3], [4], [5], [6], [7], [8], [9], [10], [11], [12], [13], [14], [15], [16], [17], [18], [19], [20], [21], [22], [23],[24], [25], [26], [27], [28], [29], [30], [31], [32], [33], [34], [35], [36], [37], [38], [39], [40], [41], [42], [43], [44], [45], [46], [47], [48], [49], [50], [51], [52], [53], [54], [55], [56], [57], [58],[59], [60], [61], [62], [63], [64], [65], [66], [67], [68], [69], [70], [71], [72], [73], [74], [75], [76], [77], [78], [79], [80], [81], [82], [83], [84], [85], [86], [87], [88], [89], [90], [91], [92], [93],[94], [95], [96], [97], [98], [99], [100], [101], [102], [103], [104], [105], [106], [107], [108], [109], [110], [111], [112], [113], [114], [115], [116], [117], [118], [119], [120], [121], [122],[123], [124], [125], [126], [127], [128], [129], [130], [131], [132], [133], [134], [135], [136], [137], [138], [139], [140], [141], [142], [143], [144], [145], [146], [147], [148], [149], [150])) p[/font]
For more flexible code layout functionality from within SQL Server Management Studio or Visual Studio, download Red Gate SQL Prompt.
Part of the reason why you most likely are only getting verbal suggestions instead of code examples is because you've not provided
your data in a readily consumable format. Please help yourself in the future by reading and heeding the article at the first link in
my signature line below under "Helpful Links".
On to the problem.
First, let's not mess around with a small number of rows. Let's do this with a little performance testing in mind.
The following will create a million rows of randomized data the form of which is not unlike your original post.
Don't let the "million" scare you. This only takes about 4 seconds on my laptop including the creation of the
clustered index (I didn't see a candidate even for a composite PK for the given columns).
--===== Conditionally drop the test table to make reruns in SSMS easier.
-- This is not a part of the solution.
IF OBJECT_ID('tempdb..#OrderDetail','U') IS NOT NULL
DROP TABLE #OrderDetail
;
--===== Create and populate the test table on-the-fly.
-- This is not a part of the solution.
SELECT TOP 1000000
SKUO = CHAR(ABS(CHECKSUM(NEwID()))%26+65)
+ CHAR(ABS(CHECKSUM(NEwID()))%26+65)
+ CHAR(ABS(CHECKSUM(NEwID()))%26+65)
,QtyO = ABS(CHECKSUM(NEWID()))%10+1
,OrderIDO = ABS(CHECKSUM(NEWID()))%30000+10000
INTO #OrderDetail
FROM master.sys.all_columns ac1
CROSS JOIN master.sys.all_columns ac2
;
--===== Create a useful index
CREATE CLUSTERED INDEX IX_#OrderDetail_Composite01
ON #OrderDetail (OrderIDO,SKUO)
;
And, now, to solve the problem using a classic CROSS TAB. This produces the desired output for all 1 million
rows in about 11 seconds on my laptop. And, yes... it will handle virtually an unlimited number of rows.
--===== Solve the problem
WITH
ctePreAgg AS
( --=== This takes care of any possible duplicates and creates the row/column numbers
-- using simple 0 based INTEGER Division (% is Modulus)
SELECT OrderIDO
,SKUO
,QtyO = RIGHT(' ' + CAST(SUM(QtyO) AS VARCHAR(5)),5)
,Row# = (ROW_NUMBER() OVER (PARTITION BY OrderIDO ORDER BY SKUO)-1)/15
,Col# = (ROW_NUMBER() OVER (PARTITION BY OrderIDO ORDER BY SKUO)-1)%15
FROM #OrderDetail
GROUP BY OrderIDO, SKUO
) --=== This pivots the data in a very high speed fashion using an old fashioned CROSS TAB.
SELECT OrderIDO
,OrderRow# = Row#+1
,SKU01 = MAX(CASE WHEN Col# = 0 THEN SKUO ELSE '' END)
,Qty01 = MAX(CASE WHEN Col# = 0 THEN QtyO ELSE '' END)
,SKU02 = MAX(CASE WHEN Col# = 1 THEN SKUO ELSE '' END)
,Qty02 = MAX(CASE WHEN Col# = 1 THEN QtyO ELSE '' END)
,SKU03 = MAX(CASE WHEN Col# = 2 THEN SKUO ELSE '' END)
,Qty03 = MAX(CASE WHEN Col# = 2 THEN QtyO ELSE '' END)
,SKU04 = MAX(CASE WHEN Col# = 3 THEN SKUO ELSE '' END)
,Qty04 = MAX(CASE WHEN Col# = 3 THEN QtyO ELSE '' END)
,SKU05 = MAX(CASE WHEN Col# = 4 THEN SKUO ELSE '' END)
,Qty05 = MAX(CASE WHEN Col# = 4 THEN QtyO ELSE '' END)
,SKU06 = MAX(CASE WHEN Col# = 5 THEN SKUO ELSE '' END)
,Qty06 = MAX(CASE WHEN Col# = 5 THEN QtyO ELSE '' END)
,SKU07 = MAX(CASE WHEN Col# = 6 THEN SKUO ELSE '' END)
,Qty07 = MAX(CASE WHEN Col# = 6 THEN QtyO ELSE '' END)
,SKU08 = MAX(CASE WHEN Col# = 7 THEN SKUO ELSE '' END)
,Qty08 = MAX(CASE WHEN Col# = 7 THEN QtyO ELSE '' END)
,SKU09 = MAX(CASE WHEN Col# = 8 THEN SKUO ELSE '' END)
,Qty09 = MAX(CASE WHEN Col# = 8 THEN QtyO ELSE '' END)
,SKU10 = MAX(CASE WHEN Col# = 9 THEN SKUO ELSE '' END)
,Qty10 = MAX(CASE WHEN Col# = 9 THEN QtyO ELSE '' END)
,SKU11 = MAX(CASE WHEN Col# = 10 THEN SKUO ELSE '' END)
,Qty11 = MAX(CASE WHEN Col# = 10 THEN QtyO ELSE '' END)
,SKU12 = MAX(CASE WHEN Col# = 11 THEN SKUO ELSE '' END)
,Qty12 = MAX(CASE WHEN Col# = 11 THEN QtyO ELSE '' END)
,SKU13 = MAX(CASE WHEN Col# = 12 THEN SKUO ELSE '' END)
,Qty13 = MAX(CASE WHEN Col# = 12 THEN QtyO ELSE '' END)
,SKU14 = MAX(CASE WHEN Col# = 13 THEN SKUO ELSE '' END)
,Qty14 = MAX(CASE WHEN Col# = 13 THEN QtyO ELSE '' END)
,SKU15 = MAX(CASE WHEN Col# = 14 THEN SKUO ELSE '' END)
,Qty15 = MAX(CASE WHEN Col# = 14 THEN QtyO ELSE '' END)
FROM ctePreAgg
GROUP BY OrderIDO, Row#
ORDER BY OrderIDO, OrderRow#
;
For more information on CROSSTABS and PIVOTS and how CROSSTABS compare in performance to Pivots,
please see the following two articles. Once you understand what's going on in the first article, the second
article will show you how to make Dynamic CROSSTABS if the need should ever arise.
[font="Arial Black"]http://www.sqlservercentral.com/articles/T-SQL/63681/[/font]
[/url]
[font="Arial Black"]http://www.sqlservercentral.com/articles/Crosstab/65048/[/font]
[/url]
--Jeff Moden
Change is inevitable... Change for the better is not.
January 25, 2014 at 3:24 pm
pietlinden (1/24/2014)
You might want to read Dwain Camps' article on Creating Dynamic Crosstabs... that might give you some ideas.
My recommendation is that if you're going to make a recommendation to read an article, you should always provide the link. 😉
--Jeff Moden
Change is inevitable... Change for the better is not.
January 28, 2014 at 5:54 pm
pietlinden (1/24/2014)
You might want to read Dwain Camps' article on Creating Dynamic Crosstabs... that might give you some ideas.
Nice thought, but I think you're referring to the articles by Jeff that he mentioned.
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 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply