Web design and hosting, database, cloud and social media solutions that deliver business results
  • Business Solutions
    • Robotic Process Automation
    • Software
    • Database Consultancy Services
      • Data Integration
      • Datawarehouse Services
      • Power BI
      • Server Upgrade and DBA Services
    • Web Site Design Services
      • Logo Design
      • Payment Gateways
      • Web Localisation and Translation
      • Web Site Optimisation
      • Web Site Security
      • Technical Tools
    • Cloud Services
      • Amazon Web Services
      • Google Cloud Services
      • Microsoft Azure
    • Microsoft Office
    • Social Media Management and Advice Services
  • Academy
    • Our Test Environment
    • Learning Databases
      • The Basics
      • Get Open Query
      • SQL Server Data
      • SQL Server Maintenance
      • Using SQL Server Dates
      • Using SQL Server Functions
      • Using SQL Server Pivot-Unpivot
      • Technical Tools
    • Learning Web Design
      • Building Ousia Content Management System
      • Using ASP-NET
      • Using CSS
      • Using JavaScript
    • Learning Cloud and IT Services
      • Task Scheduler Error 2147943645
      • Requesting SSL and Generation of PFX file in OpenSSL Simple Steps
    • Using Social Media
      • Asking for a Google Review
      • Changing a Facebook account from personal to business
      • Choosing where to focus Social Media effort
      • Social Media Image Sizes
      • Using Meta Data to set Social Media Images
  • About Us
    • Blog
      • Building an entry level gaming machine
      • Google Core Update Jan 2020
      • Hot Chilli Internet Closure
      • How To Choose Content For Your Website Adverts Leaflets
      • Preventing Online Scam
      • Skimmers of the gig economy
      • The most annoying things about websites on the Internet
      • Top 5 websites for free Vector Graphics
    • Careers
      • Translator English-Portuguese
      • Translator English-Spanish
    • Portfolio
    • Team
      • Adrian Anandan
      • Ali Al Amine
      • Ayse Hur
      • Chester Copperpot
      • Deepika Bandaru
      • Gavin Clayton
      • Sai Gangu
      • Suneel Kumar
      • Surya Mukkamala
عربى (AR)čeština (CS)Deutsch (DE)English (EN-GB)English (EN-US)Español (ES)فارسی (FA)Français (FR)हिंदी (HI)italiano (IT)日本語 (JA)polski (PL)Português (PT)русский (RU)Türk (TR)中国的 (ZH)

SQL Server using UNPIVOT to turn columns into rows

SQL Server using the UNPIVOT function in a real world type scenario.

The case for getting rid of CASE

Using Pivot/Unpivot

Many of the projects we have worked on involved working with data stored in a table with months 1 to 12 stored by year. This is not an uncommon solution, but can cause SQL statements to get bloated with dozens of CASE statements.

These CASE statements make it harder to maintain, and can also be a source of human error. 

Below, we have created a simple data set set out as per a real world example, and SQL Server has a function that will turn columns into rows.

UnPivIDUnPivYearM1M2M3M4M5M6M7M8M9M10M11M12
12010123456789101112
12011123456789101112
12012123456789101112
22010123456789101112

The case for getting rid of CASE

If you are running below SQL Server 2012, then you will need to create this function, which is an equivalent to the DATEFROMPARTS function built in from 2012
More: SQL Server function DATEFROMPARTS for pre 2012 versions

The case for getting rid of CASE

Next we can create a temp table, and populate it with the example data above.

SQL

DECLARE @UnPiv TABLE (UnPivID INT, UnPivYear SMALLINT, M1 INT, M2 INT, M3 INT, M4 INT, M5 INT, M6 INT, M7 INT, M8 INT, M9 INT, M10 INT, M11 INT, M12 INT)INSERT INTO @UnPiv(UnPivID,UnPivYear,M1,M2,M3,M4,M5,M6,M7,M8,M9,M10,M11,M12)SELECT 1,2010,1,2,3,4,5,6,7,8,9,10,11,12INSERT INTO @UnPiv(UnPivID,UnPivYear,M1,M2,M3,M4,M5,M6,M7,M8,M9,M10,M11,M12)SELECT 1,2011,1,2,3,4,5,6,7,8,9,10,11,12INSERT INTO @UnPiv(UnPivID,UnPivYear,M1,M2,M3,M4,M5,M6,M7,M8,M9,M10,M11,M12)SELECT 1,2012,1,2,3,4,5,6,7,8,9,10,11,12INSERT INTO @UnPiv(UnPivID,UnPivYear,M1,M2,M3,M4,M5,M6,M7,M8,M9,M10,M11,M12)SELECT 2,2010,1,2,3,4,5,6,7,8,9,10,11,12
SELECT UnPivID,UnPivYear,REPLACE(col,'M','') UnPivMonth,dbo.c1bs_DateFromParts(UnPivYear,REPLACE(col,'M',''),1) UnPivDate,DateFromParts(UnPivYear,REPLACE(col,'M',''),1) UnPivDateFrom2012,valFROM @UnPivUNPIVOT (Val FOR col IN (M1,M2,M3,M4,M5,M6,M7,M8,M9,M10,M11,M12)) unpiv

The case for getting rid of CASE

This should return a dataset as per below.

Results

UnPivIDUnPivYearUnPivMonthUnPivDateUnPivDate2012val
12010101/01/201001/01/20101
12010201/02/201001/02/20102
12010301/03/201001/03/20103
12010401/04/201001/04/20104
12010501/05/201001/05/20105
12010601/06/201001/06/20106
12010701/07/201001/07/20107
12010801/08/201001/08/20108
12010901/09/201001/09/20109
120101001/10/201001/10/201010
120101101/11/201001/11/201011
120101201/12/201001/12/201012
12011101/01/201101/01/20111
12011201/02/201101/02/20112
12011301/03/201101/03/20113
12011401/04/201101/04/20114
12011501/05/201101/05/20115
12011601/06/201101/06/20116
12011701/07/201101/07/20117
12011801/08/201101/08/20118
12011901/09/201101/09/20119
120111001/10/201101/10/201110
120111101/11/201101/11/201111
120111201/12/201101/12/201112
12012101/01/201201/01/20121
12012201/02/201201/02/20122
12012301/03/201201/03/20123
12012401/04/201201/04/20124
12012501/05/201201/05/20125
12012601/06/201201/06/20126
12012701/07/201201/07/20127
12012801/08/201201/08/20128
12012901/09/201201/09/20129
120121001/10/201201/10/201210
120121101/11/201201/11/201211
120121201/12/201201/12/201212
22010101/01/201001/01/20101
22010201/02/201001/02/20102
22010301/03/201001/03/20103
22010401/04/201001/04/20104
22010501/05/201001/05/20105
22010601/06/201001/06/20106
22010701/07/201001/07/20107
22010801/08/201001/08/20108
22010901/09/201001/09/20109
220101001/10/201001/10/201010
220101101/11/201001/11/201011
220101201/12/201001/12/201012

Was this helpful?

Please note, this commenting system is still in final testing.

Author

Copyright Claytabase Ltd 2020

Registered in England and Wales 08985867

Site Links

RSSLoginLink Cookie PolicySitemap

Social Media

facebook.com/Claytabaseinstagram.com/claytabase/twitter.com/Claytabaselinkedin.com/company/claytabase-ltd

Get in Touch

+15125961417info@claytabase.comClaytabase USA, 501 Congress Avenue, Suite 150, Austin, Texas, 78701, United States

Partnered With

The settings on this site are set to allow all cookies. These can be changed on our Cookie Policy & Settings page.
By continuing to use this site you agree to the use of cookies.
Ousia Logo
Logout
Ousia CMS Loader