December 9, 2005 at 3:40 pm
Hi Experts,
I have a Sales_Summary_Table in SQL Server 2000:
Location_2 Measure_Name Location_1 Measure_Value
District 1058 A CompSales A Charlotte 13499.9
District 1050 A CompSales A Charlotte 14220.1
District 1050 A NonCompSales A Charlotte 0
District 1058 Afternoon Ticket Cnt A Charlotte 409
District 1050 Breakfast Ticket Cnt A Charlotte 481
District 1058 Dinner Ticket Cnt A Charlotte 477
How to write a T-SQL in SQL Server to get the result like the following:
(Location_2 becomes the columns)
Measure_Name Location 1 District 1058 District 1050
A CompSales A Charlotte 13499.9 14220.1
A NonCompSales A Charlotte 0 0
Afternoon Ticket Cnt A Charlotte 409 0
Breakfast Ticket Cnt A Charlotte 0 481
Dinner Ticket Cnt A Charlotte 477 0
Thank you in advance.
December 9, 2005 at 3:58 pm
Forum search on keyword "Pivot":
http://www.sqlservercentral.com/forums/shwmessage.aspx?forumid=8&messageid=238656#bm238751
December 11, 2005 at 9:57 pm
Jennifer,
Since you want this done in OLTP instead of OLAP, these are more commonly known as "crosstabs" and they run pretty darned fast especially when compared to a cursor and especially when indexed correctly...
SELECT Measure_Name,
Location_1 AS [Location 1],
SUM(CASE WHEN Location_2 = 'District 1058'
THEN Measure_Value ELSE 0 END) AS [District 1058],
SUM(CASE WHEN Location_2 = 'District 1050'
THEN Measure_Value ELSE 0 END) AS [District 1050],
SUM(Measure_Value) AS Total
FROM #yourtable
GROUP BY Measure_Name,Location_1
If you follow the link previously provided, it will eventually lead you to two examples... one's a cursor and one's a single row example... neither of those are my favorite method especially when it comes to performance.
--Jeff Moden
Change is inevitable... Change for the better is not.
December 11, 2005 at 11:11 pm
You can find good crosstab examples by going to http://www.sqlteam.com, clicking on the articles, and searching for either pivot table or cross tab. There are two or three pretty good articles about it.
Derrick Leggett
Mean Old DBA
When life gives you a lemon, fire the DBA.
December 12, 2005 at 8:13 am
Hi Jeff,
Thank you for your reply. But I am sorry that I didn't explain my situation clearly.
The Location_2 has more than 40 different values and it can be changed/added/deleted anytime depend on company's operation decision. Is there any way that I can "crosstabs" the location_2 without using case?
December 12, 2005 at 10:23 am
Jenifer
Take a look at Jeffs solution for my 'pivot' problem.
http://www.sqlservercentral.com/forums/shwmessage.aspx?forumid=8&messageid=242919
It builds the Case statement for you, & I think is a very elegant solution to this thorny problem.
Dave J
December 12, 2005 at 6:05 pm
David is correct... his link leads to some code I wrote for him to make a "dynamic" cross-tab. Might have a fat-finger here and there but David wrote and posted his actual working solution which is also, pretty cool.
--Jeff Moden
Change is inevitable... Change for the better is not.
Viewing 7 posts - 1 through 6 (of 6 total)
You must be logged in to reply to this topic. Login to reply