--- { "title": "GROUP BY", "language": "en" } --- # GROUP BY ## description GROUP BY `GROUPING SETS` | `CUBE` | `ROLLUP` is an extension to GROUP BY clause. This syntax lets you define multiple groupings in the same query. GROUPING SETS produce a single result set that is equivalent to a UNION ALL of differently grouped rows For example GROUPING SETS clause: ``` SELECT a, b, SUM( c ) FROM tab1 GROUP BY GROUPING SETS ( (a, b), (a), (b), ( ) ); ``` This statement is equivalent to: ``` SELECT a, b, SUM( c ) FROM tab1 GROUP BY a, b UNION SELECT a, null, SUM( c ) FROM tab1 GROUP BY a UNION SELECT null, b, SUM( c ) FROM tab1 GROUP BY b UNION SELECT null, null, SUM( c ) FROM tab1 ``` `GROUPING(expr)` indicates whether a specified column expression in a GROUP BY list is aggregated or not. GROUPING returns 1 for aggregated or 0 for not aggregated in the result set. `GROUPING_ID(expr [ , expr [ , ... ] ])` describes which of a list of expressions are grouped in a row produced by a GROUP BY query. The GROUPING_ID function simply returns the decimal equivalent of the binary value formed as a result of the concatenation of the values returned by the GROUPING functions. ### Syntax ``` SELECT ... FROM ... [ ... ] GROUP BY [ , ... | GROUPING SETS [, ...] ( groupSet [ , groupSet [ , ... ] ] ) | ROLLUP(expr [ , expr [ , ... ] ]) | expr [ , expr [ , ... ] ] WITH ROLLUP | CUBE(expr [ , expr [ , ... ] ]) | expr [ , expr [ , ... ] ] WITH CUBE ] [ ... ] ``` ### Parameters `groupSet` is a set of expression or column or it's alias appearing in the query block’s SELECT list. `groupSet ::= { ( expr [ , expr [ , ... ] ] )}` `expr` is expression or column or it's alias appearing in the query block’s SELECT list. ### Note doris supports PostgreSQL like syntax, for example: ``` SELECT a, b, SUM( c ) FROM tab1 GROUP BY GROUPING SETS ( (a, b), (a), (b), ( ) ); SELECT a, b,c, SUM( d ) FROM tab1 GROUP BY ROLLUP(a,b,c) SELECT a, b,c, SUM( d ) FROM tab1 GROUP BY CUBE(a,b,c) ``` `ROLLUP(a,b,c)` is equivalent to `GROUPING SETS` as follows: ``` GROUPING SETS ( (a,b,c), ( a, b ), ( a), ( ) ) ``` `CUBE ( a, b, c )` is equivalent to `GROUPING SETS` as follows: ``` GROUPING SETS ( ( a, b, c ), ( a, b ), ( a, c ), ( a ), ( b, c ), ( b ), ( c ), ( ) ) ``` ## example This is a simple example ``` > SELECT * FROM t; +------+------+------+ | k1 | k2 | k3 | +------+------+------+ | a | A | 1 | | a | A | 2 | | a | B | 1 | | a | B | 3 | | b | A | 1 | | b | A | 4 | | b | B | 1 | | b | B | 5 | +------+------+------+ 8 rows in set (0.01 sec) > SELECT k1, k2, SUM(k3) FROM t GROUP BY GROUPING SETS ( (k1, k2), (k2), (k1), ( ) ); +------+------+-----------+ | k1 | k2 | sum(`k3`) | +------+------+-----------+ | b | B | 6 | | a | B | 4 | | a | A | 3 | | b | A | 5 | | NULL | B | 10 | | NULL | A | 8 | | a | NULL | 7 | | b | NULL | 11 | | NULL | NULL | 18 | +------+------+-----------+ 9 rows in set (0.06 sec) > SELECT k1, k2, GROUPING_ID(k1,k2), SUM(k3) FROM t GROUP BY GROUPING SETS ((k1, k2), (k1), (k2), ()); +------+------+---------------+----------------+ | k1 | k2 | grouping_id(k1,k2) | sum(`k3`) | +------+------+---------------+----------------+ | a | A | 0 | 3 | | a | B | 0 | 4 | | a | NULL | 1 | 7 | | b | A | 0 | 5 | | b | B | 0 | 6 | | b | NULL | 1 | 11 | | NULL | A | 2 | 8 | | NULL | B | 2 | 10 | | NULL | NULL | 3 | 18 | +------+------+---------------+----------------+ 9 rows in set (0.02 sec) ``` ## keyword GROUP, GROUPING, GROUPING_ID, GROUPING_SETS, GROUPING SETS, CUBE, ROLLUP