Dynamic PIVOT query with totals

The PIVOT statement in SQL Server is somewhat limited, as you have to list every column that you expect.  That is, unless you use tricks to generate them dynamically.  If you need to display products in columns, you never know when a new product will be added.

I found an excellent example of how to do this, which put me down the right track. http://www.mssqltips.com/sqlservertip/2783/script-to-create-dynamic-pivot-queries-in-sql-server/

But I also needed a totals column . And I modified it to use AdventureWorks:

/*********************************

Database: AdventureWorks
Purpose: This query dynamically turns 
Product names into column names
Author: GlutenFree SQL
Date: 10/8/2013

****************************************/

USE AdventureWorks
GO

DECLARE @columns NVARCHAR(MAX), 
@columnsAdded NVARCHAR(MAX), 
@sql NVARCHAR(MAX);
SET @columns = N'';
SET @columnsAdded = N'';

SELECT @columns += N', 
p.[' + REPLACE(ProductName, '''', '') + ']',
@columnsAdded += N'
+ isnull(p.[' + REPLACE(ProductName, '''', '') + '],0)'
FROM

(

SELECT DISTINCT
Product.NAME AS ProductName
FROM Production.Product

) A
ORDER BY ProductName;

--SELECT @columns
--SELECT @columnsAdded

SET @sql = N'
SELECT TransactionYear,' 
+ STUFF(@columnsAdded, 1, 2, '') + ' as [Total], ' 
+ STUFF(@columns, 1, 2, '') + '
FROM
(
SELECT SUM(TransactionHistory.Quantity) as Quantity,
YEAR(TransactionHistory.TransactionDate) as TransactionYear,
Product.NAME AS ProductColumn
FROM Production.TransactionHistory
INNER JOIN Production.Product 
  ON Product.ProductID = TransactionHistory.ProductID
GROUP BY Product.Name, YEAR(TransactionHistory.TransactionDate)

) AS j
PIVOT
(
SUM(Quantity) FOR ProductColumn IN ('
+ STUFF(REPLACE(@columns, ', p.[', ',['), 1, 1, '')
+ ')
) AS p
;';

EXEC sp_executesql @sql;
Advertisements
This entry was posted in Uncategorized. Bookmark the permalink.

Leave a Reply

Fill in your details below or click an icon to log in:

WordPress.com Logo

You are commenting using your WordPress.com account. Log Out / Change )

Twitter picture

You are commenting using your Twitter account. Log Out / Change )

Facebook photo

You are commenting using your Facebook account. Log Out / Change )

Google+ photo

You are commenting using your Google+ account. Log Out / Change )

Connecting to %s