Home > SQLServer, SQLServer 2005, SQLServer 2008, SQLServer 2008 R2 > SQL Server – TSQL – GROUP BY CUBE()

SQL Server – TSQL – GROUP BY CUBE()


CUBE() produces the result set by generating all combinations of columns specified in GROUP BY CUBE(). As with GROUP BY ROLLUP() it adds sub-total and grand-total rows as well.

For example, consider below data:

— © 2011 – Vishal (http://SqlAndMe.com)

 

SELECT      [Group], [Name], [SalesYTD]

FROM        dbo.Sales

Result Set:

Group                Name          SalesYTD

——————-  ————  —————

North America        Northwest     123237.00

South America        Northwest      37534.00

South America        Southwest      39667.00

North America        Southwest     164232.00

 

(4 row(s) affected)

When we apply GROUP BY CUBE([Group], [Name]) to this data, it will generate:

1. Combination of all columns specified:

([Group]) – 2 rows (North America, South America)

([Name]) – 2 rows (Northwest, Southwest)

2. Sub-total rows:

Sub-total for Northwest, Southwest  – 2 rows

Sub-total for North America, South America – 2 rows

3. Grand-total row: 1 row

Thereby, the result set will contain 9 rows as below:

SELECT      COALESCE([Group], 'ALL') AS 'Group',

            COALESCE([Name],'ALL') AS 'Name',

            SUM([SalesYTD]) AS 'Total Sales'

FROM        dbo.Sales

GROUP BY CUBE ([Group], [Name])

Result Set:

Group                Name                 Total Sales

——————-  ——————-  ——————

North America        Northwest            123237.00

South America        Northwest             37534.00

ALL                  Northwest            160771.00

North America        Southwest            164232.00

South America        Southwest             39667.00

ALL                  Southwest            203899.00

ALL                  ALL                  364670.00

North America        ALL                  287469.00

South America        ALL                   77201.00

 

(9 row(s) affected)

 

If GROUP BY ROLLUP() is used here, it will generate 7 rows, removing 2 sub-total rows for [Group] column from the result set:

SELECT      COALESCE([Group], 'ALL') AS 'Group',

            COALESCE([Name],'ALL') AS 'Name',

            SUM([SalesYTD]) AS 'Total Sales'

FROM        dbo.Sales

GROUP BY ROLLUP ([Group], [Name])

Result Set:

Group                Name                 Total Sales

——————-  ——————-  ——————

North America        Northwest            123237.00

North America        Southwest            164232.00

North America        ALL                  287469.00

South America        Northwest            37534.00

South America        Southwest            39667.00

South America        ALL                  77201.00

ALL                  ALL                  364670.00

 

(7 row(s) affected)

 

Hope This Helps!

Vishal

  1. Dev SQL
    28.03.2013 02:09 | #1

    Thank s for for your article.
    I think is useless for SSRS but it s interesting for other development.

  1. No trackbacks yet.