15 Mar 2012

UNPIVOT Multiple Columns


Unlike PIVOT which de-normalizes the data, UNPIVOT is more helpful in getting your data back to a more normalized form.
UNPIVOT performs the opposite operation to PIVOT by rotating columns of a table-valued expression into column values.
For a single column UNPIVOT examples and for more on PIVOT and UNPIVOT you can read from Microsoft Books Online Using PIVOT and UNPIVOT
In this article I’ll try to show you how to UNPIVOT multiple columns in a single query. There is simple trick to do that, if you are familiar with the UNPIVOT operator you will find it easy to understand.
First lets create some sample data :
-- Create sample table
CREATE TABLE Suppliers
(Id INT,
Product VARCHAR(500),
Supplier1 VARCHAR(500),
Supplier2 VARCHAR(500),
Supplier3 VARCHAR(500),
City1 VARCHAR(500),
City2 VARCHAR(500),
City3 VARCHAR(500)
)
GO

-- Load Sample data
INSERT INTO Suppliers SELECT
1, 'Car', 'Tata Motors', 'Bajaj', 'Mahindra', 'Jamshedpur','Pune','Mumbai'
UNION ALL SELECT
2, 'Bike', 'Bajaj', 'Hero Honda', 'Suzuki', 'Pune', 'New Delhi', 'Chandigarh'
UNION ALL SELECT
3, 'Cycle', 'Hercules', 'Hero', 'Atlas', 'Mumbai', 'Banglaore', 'Pune'
GO

-- Test sample data
SELECT Id, Product, Supplier1, Supplier2, Supplier3, City1, City2, City3
FROM Suppliers
GO
Here is how our sample table looks like :
IdProductSupplier1Supplier2Supplier3City1City2City3
1CarTataMotorsBajajMahindraJamshedpurPuneMumbai
2BikeBajajHero HondaSuzukiPuneNew DelhiChandigarh
3CycleHerculesHeroAtlasMumbaiBangalorePune
And as you can see here we have 2 columns which needs to be UNPIVOT, first is Supplier and second is there respective Cities.  If it was single column to be UNPIVOTed it could have been a straight forward task.  Thing is you can write a query with 2 UNPIVOT operators, but question is how to JOIN two UNPIVOT sub queries correctly so we will get the each supplier with its respective city next to it in second column?
As I said earlier there is simple trick to do that.  See the following query and its WHERE condition :
SELECT Id,
    Product,
    ROW_NUMBER()OVER(Partition By Id Order By Suppliers) as SuppId,
    SupplierName,
    CityName
FROM
(
SELECT Id, Product, Supplier1, Supplier2, Supplier3, City1, City2, City3
FROM Suppliers
) Main


UNPIVOT
(
SupplierName FOR Suppliers IN (Supplier1, Supplier2, Supplier3)
) Sup


UNPIVOT
(
CityName For Cities IN (City1, City2, City3)
) Ct


WHERE RIGHT(Suppliers,1) =  RIGHT(Cities,1)

And here is the Output of the query : 
IdProductSuppIdSupplierNameCityName
1Car1Tata MotorsJamshedpur
1Car2BajajPune
1Car3MahindraMumbai
2Bike1BajajPune
2Bike2Hero HondaNew Delhi
2Bike3SuzukiChandigarh
3Cycle1HerculesMumbai
3Cycle2HeroBangalore
3Cycle3AtlasPune
So the trick was this where condition -
WHERE RIGHT(Suppliers,1) =  RIGHT(Cities,1)
There are other ways also to UNPIVOT the multiple columns, may be some other time I’ll post them too. 
Source of inspiration for this post is following thread on MSDN forums -http://social.msdn.microsoft.com/Forums/en-US/transactsql/thread/54626179-ee9f-4db7-a31e-c02104bdd6beAt 
At the end of it, OP also come up with his own solution he got from SQLTeam’s forums.

No comments:

Post a Comment