GROUP BY clause (Databricks SQL)

Groups rows based on a set of specified grouping expressions and compute aggregations on the group of rows based on one or more specified aggregate functions. Databricks SQL also supports advanced aggregations to do multiple aggregations for the same input record set using GROUPING SETS, CUBE, ROLLUP clauses. When a you attach a FILTER clause to an aggregate function, only the matching rows are passed to that function.

Syntax

GROUP BY group_expression [, ...]
    [ WITH ROLLUP | WITH CUBE | GROUPING SETS (grouping_set [, ...]) ]

GROUP BY GROUPING SETS (grouping_set [, ...])

While aggregate functions are defined as

aggregate_name ( [ DISTINCT ] expression [, ...] ) [ FILTER ( WHERE boolean_expression ) ]

Parameters

  • GROUPING SETS

    Groups the rows for each subset of the expressions specified in the grouping sets. For example, GROUP BY GROUPING SETS (warehouse, product) is semantically equivalent to union of results of GROUP BY warehouse and GROUP BY product. This clause is a shorthand for a UNION ALL where each leg of the UNION ALL operator performs aggregation of subset of the columns specified in the GROUPING SETS clause.

  • grouping_set

    A grouping set is specified by zero or more comma-separated expressions in parentheses.

    Syntax: ( [ expression [, ...] ] )

  • grouping_expression

    The criteria based on which the rows are grouped together. The grouping of rows is performed based on result values of the grouping expressions. A grouping expression may be a column alias, a column position or an expression.

  • ROLLUP

    Specifies multiple levels of aggregations in a single statement. This clause is used to compute aggregations based on multiple grouping sets. ROLLUP is a shorthand for GROUPING SETS. For example, GROUP BY warehouse, product WITH ROLLUP is equivalent to GROUP BY GROUPING SETS ((warehouse, product), (warehouse), ()). The N elements of a ROLLUP specification results in N+1 GROUPING SETS.

  • CUBE

    CUBE clause is used to perform aggregations based on combination of grouping columns specified in the GROUP BY clause. CUBE is a shorthand for GROUPING SETS. For example, GROUP BY warehouse, product WITH CUBE is equivalent to GROUP BY GROUPING SETS ((warehouse, product), (warehouse), (product), ()). The N elements of a CUBE specification results in 2^N GROUPING SETS.

  • aggregate_name

    An aggregate function name (MIN, MAX, COUNT, SUM, AVG, etc.).

  • DISTINCT

    Removes duplicates in input rows before they are passed to aggregate functions.

  • FILTER

    Filters the input rows for which the boolean_expression in the WHERE clause evaluates to true are passed to the aggregate function; other rows are discarded.

Examples

CREATE TEMP VIEW dealer (id, city, car_model, quantity) AS
VALUES (100, 'Fremont', 'Honda Civic', 10),
       (100, 'Fremont', 'Honda Accord', 15),
       (100, 'Fremont', 'Honda CRV', 7),
       (200, 'Dublin', 'Honda Civic', 20),
       (200, 'Dublin', 'Honda Accord', 10),
       (200, 'Dublin', 'Honda CRV', 3),
       (300, 'San Jose', 'Honda Civic', 5),
       (300, 'San Jose', 'Honda Accord', 8);

-- Sum of quantity per dealership. Group by `id`.
> SELECT id, sum(quantity) FROM dealer GROUP BY id ORDER BY id;
 100            32
 200            33
 300            13

-- Use column position in GROUP by clause.
> SELECT id, sum(quantity) FROM dealer GROUP BY 1 ORDER BY 1;
 100            32
 200            33
 300            13

-- Multiple aggregations.
-- 1. Sum of quantity per dealership.
-- 2. Max quantity per dealership.
> SELECT id, sum(quantity) AS sum, max(quantity) AS max FROM dealer GROUP BY id ORDER BY id;
 100  32  15
 200  33  20
 300  13   8

-- Count the number of distinct dealer cities per car_model.
> SELECT car_model, count(DISTINCT city) AS count FROM dealer GROUP BY car_model;
  Honda Civic     3
    Honda CRV     2
 Honda Accord     3

-- Sum of only 'Honda Civic' and 'Honda CRV' quantities per dealership.
> SELECT id, sum(quantity) FILTER (WHERE car_model IN ('Honda Civic', 'Honda CRV')) AS `sum(quantity)`
    FROM dealer
    GROUP BY id ORDER BY id;
 100            17
 200            23
 300             5

-- Aggregations using multiple sets of grouping columns in a single statement.
-- Following performs aggregations based on four sets of grouping columns.
-- 1. city, car_model
-- 2. city
-- 3. car_model
-- 4. Empty grouping set. Returns quantities for all city and car models.
> SELECT city, car_model, sum(quantity) AS sum FROM dealer
   GROUP BY GROUPING SETS ((city, car_model), (city), (car_model), ())
   ORDER BY city;
      city    car_model sum
      null         null  78
      null  HondaAccord  33
      null     HondaCRV  10
      null   HondaCivic  35
    Dublin         null  33
    Dublin  HondaAccord  10
    Dublin     HondaCRV   3
    Dublin   HondaCivic  20
   Fremont         null  32
   Fremont  HondaAccord  15
   Fremont     HondaCRV   7
   Fremont   HondaCivic  10
  San Jose         null  13
  San Jose  HondaAccord   8
  San Jose   HondaCivic   5

-- Alternate syntax for `GROUPING SETS` in which both `GROUP BY` and `GROUPING SETS`
-- specifications are present.
> SELECT city, car_model, sum(quantity) AS sum FROM dealer
   GROUP BY city, car_model GROUPING SETS ((city, car_model), (city), (car_model), ())
   ORDER BY city, car_model;
      city    car_model sum
      null         null  78
      null  HondaAccord  33
      null     HondaCRV  10
      null   HondaCivic  35
    Dublin         null  33
    Dublin  HondaAccord  10
    Dublin     HondaCRV   3
    Dublin   HondaCivic  20
   Fremont         null  32
   Fremont  HondaAccord  15
   Fremont     HondaCRV   7
   Fremont   HondaCivic  10
  San Jose         null  13
  San Jose  HondaAccord   8
  San Jose   HondaCivic   5

-- Group by processing with `ROLLUP` clause.
-- Equivalent GROUP BY GROUPING SETS ((city, car_model), (city), ())
> SELECT city, car_model, sum(quantity) AS sum FROM dealer
   GROUP BY city, car_model WITH ROLLUP
   ORDER BY city, car_model;
      null         null  78
    Dublin         null  33
    Dublin  HondaAccord  10
    Dublin     HondaCRV   3
    Dublin   HondaCivic  20
   Fremont         null  32
   Fremont  HondaAccord  15
   Fremont     HondaCRV   7
   Fremont   HondaCivic  10
  San Jose         null  13
  San Jose  HondaAccord   8
  San Jose   HondaCivic   5

-- Group by processing with `CUBE` clause.
-- Equivalent GROUP BY GROUPING SETS ((city, car_model), (city), (car_model), ())
> SELECT city, car_model, sum(quantity) AS sum FROM dealer
   GROUP BY city, car_model WITH CUBE
   ORDER BY city, car_model;
      null         null  78
      null  HondaAccord  33
      null     HondaCRV  10
      null   HondaCivic  35
    Dublin         null  33
    Dublin  HondaAccord  10
    Dublin     HondaCRV   3
    Dublin   HondaCivic  20
   Fremont         null  32
   Fremont  HondaAccord  15
   Fremont     HondaCRV   7
   Fremont   HondaCivic  10
  San Jose         null  13
  San Jose  HondaAccord   8
  San Jose   HondaCivic   5

--Prepare data for ignore nulls example
> CREATE TEMP VIEW person (id, name, age) AS
   VALUES (100, 'Mary', NULL),
          (200, 'John', 30),
          (300, 'Mike', 80),
          (400, 'Dan' , 50);

--Select the first row in cloumn age
> SELECT FIRST(age) FROM person;
  NULL

--Get the first row in cloumn `age` ignore nulls,last row in column `id` and sum of cloumn `id`.
> SELECT FIRST(age IGNORE NULLS), LAST(id), SUM(id) FROM person;
  30                  400                1000