Problem :
Table1 had 11 columns, one column being the id of the row and the other 10 columns referencing Table2 (which just stored an ID and Description)
We were required to return a single row from Table1 with its ID and for each of the other 10 columns their corresponding description from Table2.
Solution :
Use UNPIVOT to convert all the columns of a single row from Table1 into multiple rows which hold each of the 10 reference columns. Then join it with Table2 to get the description. Finally PIVOT the result of the join to get back our single row with descriptions instead of IDs.
Brief description of PIVOT AND UNPIVOT
PIVOT (simplified definition)
Pivot is used when you want to convert the unique values of a column(spanning accross multiple rows) into multiple columns (column names) of a row in the output. The final output can also contain aggregations on the other columns required in the output.
UNPIVOT
Unpivot performs exactly opposite of Pivot. It converts the values of different columns in a single row to multiple rows in the output
Note:
- Pivot/Unpivot can only be used it the compatibility of the database is set to 90 or higher.
- Applying Unpivot to Pivot might not result in the same data due to the application of aggregations.
Solution with Example:
In order to demonstrate the use of Pivot and Unpivot we will be creating two tables :
First Table : ValueTable -- this table contains ID and Name
CREATE TABLE dbo.ValueTable(
ID INT IDENTITY(1,1) PRIMARY KEY
,Name VARCHAR(50) NOT NULL
)
Second Table : TableWithReferences -- contains an ID column and 5 other columns which reference the ValueTable's ID column
CREATE TABLE dbo.TableWithReferences(
ID INT IDENTITY(1,1) PRIMARY KEY
,RefCol1 INT FOREIGN KEY REFERENCES ValueTable(ID)
,RefCol2 INT FOREIGN KEY REFERENCES ValueTable(ID)
,RefCol3 INT FOREIGN KEY REFERENCES ValueTable(ID)
,RefCol4 INT FOREIGN KEY REFERENCES ValueTable(ID)
,RefCol5 INT FOREIGN KEY REFERENCES ValueTable(ID)
)
Now lets populate each table with some data to work with
INSERT INTO ValueTable(Name)
VALUES('First'), ('Second'), ('Third'), ('Fourth'), ('Fifth')
INSERT INTO TableWithReferences(RefCol1,RefCol2,RefCol3,RefCol4,RefCol5)
VALUES (1,2,3,4,5), (1,1,3,3,2)
We need to write a query which should give out the same result as the following query
DECLARE @ID AS INT
SET @ID = 2
SELECT TR.ID
,V1.Name AS RefCol1
,V2.Name AS RefCol2
,V3.Name AS RefCol3
,V4.Name AS RefCol4
,V5.Name AS RefCol5
FROM TableWithReferences TR
INNER JOIN ValueTable V1
ON TR.RefCol1 = V1.ID
INNER JOIN ValueTable V2
ON TR.RefCol2 = V2.ID
INNER JOIN ValueTable V3
ON TR.RefCol3 = V3.ID
INNER JOIN ValueTable V4
ON TR.RefCol4 = V4.ID
INNER JOIN ValueTable V5
ON TR.RefCol5 = V5.ID
WHERE
TR.ID = @ID
Output of the query above :
ID RefCol1 RefCol2 RefCol3 RefCol4 RefCol5
2 First First Third Third Second
The problem with the query above is that it requires too many joins. Lets take a look at how we can solve this problem by using Pivot and Unpivot
Now lets cook up some queries to solve this problem
Lets start by writing a query to display the Column name and its reference value in each row.
DECLARE @ID AS INT
SET @ID = 2
SELECT ValueTableID
,ReferenceColumn
FROM (
SELECT RefCol1
,RefCol2
,RefCol3
,RefCol4
,RefCol5
FROM TableWithReferences
WHERE
ID = @ID
)P
UNPIVOT(
ValueTableID
FOR ReferenceColumn IN(RefCol1, RefCol2, RefCol3, RefCol4, RefCol5)
) AS Unpvt
the result of this query is :
ValueTableID ReferenceColumn
------------ -----------------
1 RefCol1
1 RefCol2
3 RefCol3
3 RefCol4
2 RefCol5
Now joining the previous query with Value table will give us the Names instead of IDs
DECLARE @ID AS INT
SET @ID = 2
SELECT ReferenceColumn, Name
FROM
(
SELECT ValueTableID
,ReferenceColumn
FROM (
SELECT RefCol1
,RefCol2
,RefCol3
,RefCol4
,RefCol5
FROM TableWithReferences
WHERE
ID = @ID
)P
UNPIVOT(
ValueTableID
FOR ReferenceColumn IN(RefCol1, RefCol2, RefCol3, RefCol4, RefCol5)
) AS Unpvt
) P
INNER JOIN ValueTable V
ON P.ValueTableID = V.ID
query's output:
ReferenceColumn Name
RefCol1 First
RefCol2 First
RefCol3 Third
RefCol4 Third
RefCol5 Second
Now that we have got the Names from IDs, its time to unpivot the result to get our single row
DECLARE @ID AS INT
SET @ID = 2
SELECT @ID as ID, RefCol1, RefCol2, RefCol3, RefCol4, RefCol5
FROM
(
SELECT ReferenceColumn, Name
FROM
(
SELECT ValueTableID
,ReferenceColumn
FROM (
SELECT RefCol1
,RefCol2
,RefCol3
,RefCol4
,RefCol5
FROM TableWithReferences
WHERE
ID = @ID
)P
UNPIVOT(
ValueTableID
FOR ReferenceColumn IN(RefCol1, RefCol2, RefCol3, RefCol4, RefCol5)
) AS Unpvt
) P
INNER JOIN ValueTable V
ON P.ValueTableID = V.ID
) pv
PIVOT
(MAX(Name) FOR ReferenceColumn IN ([RefCol1], [RefCol2], [RefCol3], [RefCol4], [RefCol5])) P
Output of this query :
ID RefCol1 RefCol2 RefCol3 RefCol4 RefCol5
2 First First Third Third Second
This output is same as the output of the query with lots of joins.
Hope this post was informative and helpful.
Any suggestions or comments are welcome.