In this blog post I want to discuss a problem I encounter frequently in SQL related forums – how to perform dynamic PIVOT involving multiple columns using pure T-SQL solution. In SQL Server Reporting Services this functionality can be easily achieved using Matrix template.

With the introduction of PIVOT operator in SQL 2005, it became very easy to write queries that transform rows into columns. There are numerous articles on the Web as how to perform PIVOT and even dynamic PIVOT. However, most of these articles explain how to perform such queries for just one column. I want to expand the transformation for multiple columns.

The idea of a solution is quite simple – you need to generate the SQL dynamically. Since we want to use pivot on multiple columns, we need to use CASE based pivot.

You need to keep in mind, that resulting query should have less than 1024 columns. You may build the check for number of columns into the query.

Now, every time I need to create a dynamic query, I need to know what is the final query I am going to arrive to. Having the idea in mind and printing the SQL command until I got it right helps to create the working query.

Let’s consider the first example based on the AdventureWorks SalesOrderHeader table.

This code creates the table we’re going to transform – it gives us summary of orders and total due per each quarter:

USE AdventureWorks 

SELECT   DATEPART(quarter,OrderDate) AS [Quarter], 
         DATEPART(YEAR,OrderDate)    AS [Year], 
         COUNT(SalesOrderID)         AS [Orders Count], 
         SUM(TotalDue)               AS [Total Due] 
INTO     #SalesSummary 
FROM     Sales.SalesOrderHeader 
GROUP BY DATEPART(quarter,OrderDate), 
         DATEPART(YEAR,OrderDate) 

SELECT   * 
FROM     #SalesSummary 
ORDER BY [Year], 
         [Quarter]

The #SalesSummary table lists count of orders and total due for each quarter and year.

Quarterly Orders Summary
QuarterYearOrders CountTotal Due
32001621$5,850,932.9483
42001758$8,476,619.278
12002741$7,379,686.3091
22002825$8,210,285.1655
320021054$13,458,206.13
420021072$10,827,327.4904
120031091$8,550,831.8702
220031260$10,749,269.374
320034152$18,220,131.5285
420035940$16,787,382.3141
120046087$14,170,982.5455
220046888$17,969,750.9487
32004976$56,178.9223

Now, suppose we want to see these results horizontally. The following dynamic SQL produces the desired output:


DECLARE  @SQL  NVARCHAR(MAX), 
    @Cols NVARCHAR(MAX)
    
SELECT @Cols = STUFF((select ', 
SUM(CASE WHEN [Quarter]=' + CAST([Quarter] as varchar(3)) + ' AND [Year] = ' + 
CAST([Year] as char(4)) + 
' THEN [Orders Count] ELSE 0 END) AS [' + 
CAST([Year] as char(4)) + '-' + CAST([Quarter] as varchar(3)) + 
' Orders], 
SUM(CASE WHEN [Quarter]=' + CAST([Quarter] as varchar(3)) + 
' AND [Year] = ' + CAST([Year] as char(4)) + 
' THEN [Total Due] ELSE 0 END) AS [' + CAST([Year] as char(4)) + '-' + 
CAST([Quarter] as varchar(3)) + ' Sales]'
FROM #SalesSummary 
ORDER BY [Year],[Quarter] FOR XML PATH(''),type).value('.','varchar(max)'),1,2,'')

SET @SQL = 'SELECT ' + @Cols + '  FROM #SalesSummary' 

--print @SQL 
EXECUTE( @SQL)

It produces the transformed result (I show only few first columns):

Transformed result
2001-3 Orders2001-3 Sales2001-4 Orders2001-4 Sales2002-1 Orders2002-1 Sales2002-2 Orders2002-2 Sales
621$5,850,932.9483758$8,476,619.278741$7,379,686.3091825$8,210,285.1655

You may want to un-comment PRINT @SQL statement if you want to see the generated command. I used XML PATH to concatenate rows into a string based on this blog post by Brad Schulz Making a list and checking it twice.

Another interesting problem was presented in this MSDN Transact-SQL forum thread:

For the claims table that has many integer columns, transform rows into columns. I demonstrate just the solution with the table creation script:

USE tempdb 

IF OBJECT_ID('Claims','U') IS NOT NULL 
DROP TABLE Claims 

GO 

CREATE TABLE Claims ( 
Claim  INT, 
HCPC   INT, 
[mod]  INT, 
charge INT, 
paid   INT, 
Qty    INT) 

INSERT INTO Claims 
SELECT 12345, 
  99245, 
  90, 
  20, 
  10, 
  1 
UNION ALL 
SELECT 12345, 
  99112, 
  NULL, 
  30, 
  20, 
  1 
UNION ALL 
SELECT 12345, 
  99111, 
  80, 
  50, 
  25, 
  2 
UNION ALL 
SELECT 11112, 
  99911, 
  60, 
  50, 
  20, 
  1 
UNION ALL 
SELECT 12222, 
  99454, 
  NULL, 
  50, 
  20, 
  1 

SELECT * FROM Claims

The output is:

<th>
  HCPC
</th>

<th>
  mod
</th>

<th>
  Charge
</th>

<th>
  Paid
</th>

<th>
  Qty
</th>
<td align="right" style="width: 20%">
  99245
</td>

<td align="right" style="width: 20%">
  90
</td>

<td align="right" style="width: 20%">
  20
</td>

<td align="right" style="width: 20%">
  10
</td>

<td align="right" style="width: 20%">
  1
</td>
<td align="right" style="width: 20%">
  99112
</td>

<td align="right" style="width: 20%">
  NULL
</td>

<td align="right" style="width: 20%">
  30
</td>

<td align="right" style="width: 20%">
  20
</td>

<td align="right" style="width: 20%">
  1
</td>
<td align="right" style="width: 20%">
  99111
</td>

<td align="right" style="width: 20%">
  80
</td>

<td align="right" style="width: 20%">
  50
</td>

<td align="right" style="width: 20%">
  25
</td>

<td align="right" style="width: 20%">
  2
</td>
<td align="right" style="width: 20%">
  99911
</td>

<td align="right" style="width: 20%">
  60
</td>

<td align="right" style="width: 20%">
  50
</td>

<td align="right" style="width: 20%">
  20
</td>

<td align="right" style="width: 20%">
  1
</td>
<td align="right" style="width: 20%">
  99454
</td>

<td align="right" style="width: 20%">
  NULL
</td>

<td align="right" style="width: 20%">
  50
</td>

<td align="right" style="width: 20%">
  20
</td>

<td align="right" style="width: 20%">
  1
</td>
Claims table
Claim
12345
12345
12345
11112
12222

And the following code transforms the result (as you see, I am using a loop and ROW_NUMBER() approach):

DECLARE  @SQL     NVARCHAR(MAX), 
    @Loop    INT, 
    @MaxRows INT 

SET @Sql = '' 

SELECT @MaxRows = MAX(MaxRow) 
FROM   (SELECT   COUNT(* ) AS MaxRow, 
            Claim 
  FROM     Claims 
  GROUP BY Claim) X 

SET @Loop = 1 

WHILE @Loop <= @MaxRows 
BEGIN 
SELECT @SQL = @SQL + ',     SUM(CASE WHEN Row = ' + CAST(@Loop AS VARCHAR(10)) + ' THEN ' + QUOTENAME(Column_Name) + ' END) AS [' + COLUMN_NAME + CAST(@Loop AS VARCHAR(10)) + ']'
FROM   INFORMATION_SCHEMA.COLUMNS 
WHERE  TABLE_Name = 'Claims' 
      AND COLUMN_NAME NOT IN ('Row','Claim') 

SET @Loop = @Loop + 1 
END 

--PRINT @SQL 
SET @SQL = 'SELECT Claim' + @SQL + ' FROM (select *,          row_number() over (partition by Claim ORDER BY Claim) as Row         FROM Claims) X GROUP BY Claim ' 

PRINT @SQL 

EXECUTE( @SQL)
<th>
  HCPC1
</th>

<th>
  mod1
</th>

<th>
  Charge1
</th>

<th>
  Paid1
</th>

<th>
  Qty1
</th>

<th>
  HCPC2
</th>

<th>
  mod2
</th>

<th>
  Charge2
</th>

<th>
  Paid2
</th>

<th>
  Qty2
</th>

<th>
  HCPC3
</th>

<th>
  mod3
</th>

<th>
  Charge3
</th>

<th>
  Paid3
</th>

<th>
  Qty3
</th>
<td align="right" style="width: 10%">
  99911
</td>

<td align="right" style="width: 10%">
  60
</td>

<td align="right" style="width: 10%">
  50
</td>

<td align="right" style="width: 10%">
  20
</td>

<td align="right">
  1
</td>

<td align="right" style="width: 20%">
  NULL
</td>

<td align="right">
  NULL
</td>

<td align="right">
  NULL
</td>

<td align="right">
  NULL
</td>

<td align="right">
  NULL
</td>

<td align="right">
  NULL
</td>

<td align="right" style="width: 20%">
  NULL
</td>

<td align="right">
  NULL
</td>

<td align="right">
  NULL
</td>

<td align="right">
  NULL
</td>
<td align="right">
  99454
</td>

<td align="right">
  NULL
</td>

<td align="right">
  50
</td>

<td align="right">
  20
</td>

<td align="right">
  1
</td>

<td align="right" style="width: 20%">
  NULL
</td>

<td align="right">
  NULL
</td>

<td align="right">
  NULL
</td>

<td align="right">
  NULL
</td>

<td align="right">
  NULL
</td>

<td align="right">
  NULL
</td>

<td align="right">
  NULL
</td>

<td align="right">
  NULL
</td>

<td align="right">
  NULL
</td>

<td align="right">
  NULL
</td>
<td align="right">
  99245
</td>

<td align="right">
  90
</td>

<td align="right">
  20
</td>

<td align="right">
  10
</td>

<td align="right">
  1
</td>

<td align="right" style="width: 20%">
  99112
</td>

<td align="right">
  NULL
</td>

<td align="right">
  30
</td>

<td align="right">
  20
</td>

<td align="right">
  1
</td>

<td align="right">
  99111
</td>

<td align="right">
  80
</td>

<td align="right">
  50
</td>

<td align="right">
  25
</td>

<td align="right">
  2
</td>
Transformed Output
Claim
11112
12222
12345

I'll post another recent problem found in the following MSDN thread Basic Crosstab Query

SET NOCOUNT ON;
GO
USE tempdb;
GO
CREATE TABLE #T (
StoreID char(5) NOT NULL,
CriteriaNo int NOT NULL,
Result int NOT NULL, 
Position int NOT NULL,
PRIMARY KEY (StoreID, CriteriaNo)
);
GO
INSERT INTO #T(StoreID, CriteriaNo, Result, Position)
SELECT '0001', 9, 10, 1 UNION ALL 
SELECT '0002', 9, 12, 2 UNION ALL 
SELECT '0001', 10, 5, 1 UNION ALL
SELECT '0002', 10, 6, 2;
GO
-- dynamic
DECLARE @sql nvarchar(MAX), @Cols nvarchar(max);

SELECT @Cols = (select ', ' + 'MAX(case when CriteriaNo = ' + CONVERT(varchar(20), CriteriaNo) + 
' then Result else 0 end) AS CriteriaNo' + CONVERT(varchar(20), CriteriaNo) + 
', MAX(case when CriteriaNo = ' + CONVERT(varchar(20), CriteriaNo) + 
' then Position else 0 end) AS CriteriaPosition' + CONVERT(varchar(20), CriteriaNo)
from (select distinct CriteriaNo from #T) X ORDER By CriteriaNo 
FOR XML PATH(''))

SET @sql = 'SELECT StoreID' + @Cols + ', SUM(Result) as PerformancePrint
FROM #T
GROUP BY StoreID'

EXECUTE(@sql)

See also my TechNet WiKi article on this same topic with more code samples

T-SQL: Dynamic Pivot on Multiple Columns

*** Remember, if you have a SQL related question, try our Microsoft SQL Server Programming forum or our Microsoft SQL Server Admin forum