GROUPING_ID

Name

GROUPING_ID

Description

Is a function that computes the level of grouping. GROUPING_ID can be used only in the SELECT <select> list, HAVING, or ORDER BY clauses when GROUP BY is specified.

Syntax

  1. GROUPING_ID ( <column_expression>[ ,...n ] )

Arguments

<column_expression>

Is a column_expression in a GROUP BY clause.

Return Type

BIGINT

Remarks

The GROUPING_ID’s <column_expression> must exactly match the expression in the GROUP BY list. For example, if you are grouping by user_id, use GROUPING_ID (user_id); or if you are grouping by name, use GROUPING_ID (name).

Comparing GROUPING_ID() to GROUPING()

GROUPING_ID(<column_expression> [ ,...n ]) inputs the equivalent of the GROUPING(<column_expression>) return for each column in its column list in each output row as a string of ones and zeros. GROUPING_ID interprets that string as a base-2 number and returns the equivalent integer. For example consider the following statement: SELECT a, b, c, SUM(d), GROUPING_ID(a,b,c) FROM T GROUP BY <group by list>. The following table shows the GROUPING_ID() input and output values.

Columns aggregatedGROUPING_ID (a, b, c) input = GROUPING(a) + GROUPING(b) + GROUPING(c)GROUPING_ID () output
a1004
b0102
c0011
ab1106
ac1015
bc0113
abc1117

Technical Definition of GROUPING_ID()

Each GROUPING_ID argument must be an element of the GROUP BY list. GROUPING_ID() returns an integer bitmap whose lowest N bits may be lit. A lit bit indicates the corresponding argument is not a grouping column for the given output row. The lowest-order bit corresponds to argument N, and the (N-1)ᵗʰ lowest-order bit corresponds to argument 1.

GROUPING_ID() Equivalents

For a single grouping query, GROUPING (<column_expression>) is equivalent to GROUPING_ID(<column_expression>), and both return 0. For example, the following statements are equivalent:

Statement A:

  1. SELECT GROUPING_ID(A,B)
  2. FROM T
  3. GROUP BY CUBE(A,B)

Statement B:

  1. SELECT 3 FROM T GROUP BY ()
  2. UNION ALL
  3. SELECT 1 FROM T GROUP BY A
  4. UNION ALL
  5. SELECT 2 FROM T GROUP BY B
  6. UNION ALL
  7. SELECT 0 FROM T GROUP BY A,B

Example

Before starting our example, We first prepare the following data.

  1. CREATE TABLE employee (
  2. uid INT,
  3. name VARCHAR(32),
  4. level VARCHAR(32),
  5. title VARCHAR(32),
  6. department VARCHAR(32),
  7. hiredate DATE
  8. )
  9. UNIQUE KEY(uid)
  10. DISTRIBUTED BY HASH(uid) BUCKETS 1
  11. PROPERTIES (
  12. "replication_num" = "1"
  13. );
  14. INSERT INTO employee VALUES
  15. (1, 'Abby', 'Senior', 'President', 'Board of Directors', '1999-11-13'),
  16. (2, 'Bob', 'Senior', 'Vice-President', 'Board of Directors', '1999-11-13'),
  17. (3, 'Candy', 'Senior', 'System Engineer', 'Technology', '2005-3-7'),
  18. (4, 'Devere', 'Senior', 'Hardware Engineer', 'Technology', '2006-7-9'),
  19. (5, 'Emilie', 'Senior', 'System Analyst', 'Technology', '2003-8-28'),
  20. (6, 'Fredrick', 'Senior', 'Sales Manager', 'Sales', '2004-9-7'),
  21. (7, 'Gitel', 'Assistant', 'Business Executive', 'Sales', '2003-3-19'),
  22. (8, 'Haden', 'Trainee', 'Sales Assistant', 'Sales', '2007-6-30'),
  23. (9, 'Irene', 'Assistant', 'Business Executive', 'Sales', '2005-10-20'),
  24. (10, 'Jankin', 'Senior', 'Marketing Supervisor', 'Marketing', '2001-4-13'),
  25. (11, 'Louis', 'Trainee', 'Marketing Assistant', 'Marketing', '2007-8-2'),
  26. (12, 'Martin', 'Trainee', 'Marketing Assistant', 'Marketing', '2007-7-1'),
  27. (13, 'Nasir', 'Assistant', 'Marketing Executive', 'Marketing', '2004-9-3');

Here is the result.

  1. +------+----------+-----------+----------------------+--------------------+------------+
  2. | uid | name | level | title | department | hiredate |
  3. +------+----------+-----------+----------------------+--------------------+------------+
  4. | 1 | Abby | Senior | President | Board of Directors | 1999-11-13 |
  5. | 2 | Bob | Senior | Vice-President | Board of Directors | 1999-11-13 |
  6. | 3 | Candy | Senior | System Engineer | Technology | 2005-03-07 |
  7. | 4 | Devere | Senior | Hardware Engineer | Technology | 2006-07-09 |
  8. | 5 | Emilie | Senior | System Analyst | Technology | 2003-08-28 |
  9. | 6 | Fredrick | Senior | Sales Manager | Sales | 2004-09-07 |
  10. | 7 | Gitel | Assistant | Business Executive | Sales | 2003-03-19 |
  11. | 8 | Haden | Trainee | Sales Assistant | Sales | 2007-06-30 |
  12. | 9 | Irene | Assistant | Business Executive | Sales | 2005-10-20 |
  13. | 10 | Jankin | Senior | Marketing Supervisor | Marketing | 2001-04-13 |
  14. | 11 | Louis | Trainee | Marketing Assistant | Marketing | 2007-08-02 |
  15. | 12 | Martin | Trainee | Marketing Assistant | Marketing | 2007-07-01 |
  16. | 13 | Nasir | Assistant | Marketing Executive | Marketing | 2004-09-03 |
  17. +------+----------+-----------+----------------------+--------------------+------------+
  18. 13 rows in set (0.01 sec)

A. Using GROUPING_ID to identify grouping levels

The following example returns the count of employees by department and level. GROUPING_ID() is used to create a value for each row in the Job Title column that identifies its level of aggregation.

  1. SELECT
  2. department,
  3. CASE
  4. WHEN GROUPING_ID(department, level) = 0 THEN level
  5. WHEN GROUPING_ID(department, level) = 1 THEN CONCAT('Total: ', department)
  6. WHEN GROUPING_ID(department, level) = 3 THEN 'Total: Company'
  7. ELSE 'Unknown'
  8. END AS 'Job Title',
  9. COUNT(uid) AS 'Employee Count'
  10. FROM employee
  11. GROUP BY ROLLUP(department, level)
  12. ORDER BY GROUPING_ID(department, level) ASC;

Here is the result.

  1. +--------------------+---------------------------+----------------+
  2. | department | Job Title | Employee Count |
  3. +--------------------+---------------------------+----------------+
  4. | Board of Directors | Senior | 2 |
  5. | Technology | Senior | 3 |
  6. | Sales | Senior | 1 |
  7. | Sales | Assistant | 2 |
  8. | Sales | Trainee | 1 |
  9. | Marketing | Senior | 1 |
  10. | Marketing | Trainee | 2 |
  11. | Marketing | Assistant | 1 |
  12. | Board of Directors | Total: Board of Directors | 2 |
  13. | Technology | Total: Technology | 3 |
  14. | Sales | Total: Sales | 4 |
  15. | Marketing | Total: Marketing | 4 |
  16. | NULL | Total: Company | 13 |
  17. +--------------------+---------------------------+----------------+
  18. 13 rows in set (0.01 sec)

B. Using GROUPING_ID to filter a result set

In the following code, to return only the rows that have the count of senior in department.

  1. SELECT
  2. department,
  3. CASE
  4. WHEN GROUPING_ID(department, level) = 0 THEN level
  5. WHEN GROUPING_ID(department, level) = 1 THEN CONCAT('Total: ', department)
  6. WHEN GROUPING_ID(department, level) = 3 THEN 'Total: Company'
  7. ELSE 'Unknown'
  8. END AS 'Job Title',
  9. COUNT(uid)
  10. FROM employee
  11. GROUP BY ROLLUP(department, level)
  12. HAVING `Job Title` IN ('Senior');

Here is the result.

  1. +--------------------+-----------+--------------+
  2. | department | Job Title | count(`uid`) |
  3. +--------------------+-----------+--------------+
  4. | Board of Directors | Senior | 2 |
  5. | Technology | Senior | 3 |
  6. | Sales | Senior | 1 |
  7. | Marketing | Senior | 1 |
  8. +--------------------+-----------+--------------+
  9. 5 rows in set (0.01 sec)

Keywords

GROUPING_ID

Best Practice

For more information, see also: