Archive
Archive for March 23, 2015
GROUPING SETS equivalent | for SQL Server 2005 and below
March 23, 2015
4 comments
Sometime back I discussed about [GROUPING SETS] in my previous post and today one reader of this blog asked me how we can create the same result-set without using GROUPING SETS if we are on previous versions like SQL Server 2005 or 2000.
–> Let’s take the following SQL Query that uses GROUPING SETS operator and let’s see what Output we get:
-- GROUPING SETS SELECT class, section, rollno, sum(marks) [sum] FROM #tempTable GROUP BY GROUPING SETS ( (class, section, rollno) ,(class, section) ,(class) ,() )
Output:
class section rollno sum
HighSchool a 1 80
HighSchool a 2 70
HighSchool a 3 80
HighSchool a NULL 230
HighSchool b 4 90
HighSchool b 5 90
HighSchool b 6 50
HighSchool b NULL 230
HighSchool NULL NULL 460
Intermediate a 1 60
Intermediate a 2 50
Intermediate a 3 80
Intermediate a NULL 190
Intermediate b 4 90
Intermediate b 5 50
Intermediate b 6 70
Intermediate b NULL 210
Intermediate NULL NULL 400
NULL NULL NULL 860
You can refer to the DDL and population of this #tempTable in my previous post, [link].
–> And now let’s see how can we recreate the same result set without using GROUPING SETS if we are on lower versions of SQL Server (<= 2005):
-- ROLLUP and Grouping Sets Equivalent (pre SQL 2008) SELECT class, section, rollno, marks as [sum] FROM #tempTable UNION ALL SELECT class, section, null as rollnu, sum(marks) [sum] FROM #tempTable GROUP BY class, section UNION ALL SELECT class, null, null, sum(marks) [sum] FROM #tempTable GROUP BY class UNION ALL SELECT null, null, null, sum(marks) [sum] FROM #tempTable ORDER BY class DESC, section DESC, rollno DESC
Thanks, please let me know your thoughts and comments!!!
Categories: SQL Tips
CUBE, GROUP BY, GROUPING SETS, ROLLUP