From 2e74dba3d065d40a4e487c9135ec3c4c99d3d50a Mon Sep 17 00:00:00 2001 From: Dilip Biswal Date: Wed, 22 Jan 2020 18:30:42 -0600 Subject: [PATCH] [SPARK-30574][DOC] Document GROUP BY Clause of SELECT statement in SQL Reference ### What changes were proposed in this pull request? Document GROUP BY clause of SELECT statement in SQL Reference Guide. ### Why are the changes needed? Currently Spark lacks documentation on the supported SQL constructs causing confusion among users who sometimes have to look at the code to understand the usage. This is aimed at addressing this issue. ### Does this PR introduce any user-facing change? Yes. **Before:** There was no documentation for this. **After.** Screen Shot 2020-01-19 at 5 11 12 PM Screen Shot 2020-01-19 at 5 11 32 PM Screen Shot 2020-01-19 at 5 11 49 PM Screen Shot 2020-01-19 at 5 12 05 PM Screen Shot 2020-01-19 at 5 12 31 PM Screen Shot 2020-01-19 at 5 26 38 PM ### How was this patch tested? Tested using jykyll build --serve Closes #27283 from dilipbiswal/sql-ref-select-groupby. Authored-by: Dilip Biswal Signed-off-by: Sean Owen --- docs/sql-ref-syntax-qry-select-groupby.md | 209 +++++++++++++++++++++- 1 file changed, 206 insertions(+), 3 deletions(-) diff --git a/docs/sql-ref-syntax-qry-select-groupby.md b/docs/sql-ref-syntax-qry-select-groupby.md index 8ba7d155f3..2d13c34956 100644 --- a/docs/sql-ref-syntax-qry-select-groupby.md +++ b/docs/sql-ref-syntax-qry-select-groupby.md @@ -1,7 +1,7 @@ --- layout: global -title: GROUPBY Clause -displayTitle: GROUPBY Clause +title: GROUP BY Clause +displayTitle: GROUP BY Clause license: | Licensed to the Apache Software Foundation (ASF) under one or more contributor license agreements. See the NOTICE file distributed with @@ -18,5 +18,208 @@ license: | See the License for the specific language governing permissions and limitations under the License. --- +The GROUP BY clause is used to group the 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. Spark also supports advanced aggregations to do multiple +aggregations for the same input record set via `GROUPING SETS`, `CUBE`, `ROLLUP` clauses. -**This page is under construction** +### Syntax +{% highlight sql %} +GROUP BY [ GROUPING SETS grouping_sets ] group_expression [ , group_expression [ , ... ] ] + [ ( WITH ROLLUP | WITH CUBE | GROUPING SETS grouping_sets ) ) ] +{% endhighlight %} + +### 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 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_sets
+
+ Specifies one of more groupings based on which the GROUP BY clause performs aggregations. A grouping + set is specified by a list of comma-separated expressions in parentheses.

+ Syntax: + + (() | (expression [ , ...])) + +
+
grouping_expression
+
+ Specifies the critieria 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 shorthand for GROUPING SETS. For example, + GROUP BY warehouse, product WITH ROLLUP is equivalent to GROUP BY warehouse, product 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. For example, GROUP BY warehouse, product WITH CUBE is equivalent + to GROUP BY warehouse, product GROUPING SETS ((warehouse, product), (warehouse), (product), ()). + The N elements of a CUBE specification results in 2^N GROUPING SETS. +
+
+ +### Examples +{% highlight sql %} +CREATE TABLE dealer (id INT, city STRING, car_model STRING, quantity INT); +INSERT INTO dealer 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; + + +---+-------------+ + |id |sum(quantity)| + +---+-------------+ + |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; + + +---+-------------+ + |id |sum(quantity)| + +---+-------------+ + |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; + + +---+---+---+ + |id |sum|max| + +---+---+---+ + |100|32 |15 | + |200|33 |20 | + |300|13 |8 | + +---+---+---+ + +-- 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 |Honda Accord|33 | + |null |Honda CRV |10 | + |null |Honda Civic |35 | + |Dublin |null |33 | + |Dublin |Honda Accord|10 | + |Dublin |Honda CRV |3 | + |Dublin |Honda Civic |20 | + |Fremont |null |32 | + |Fremont |Honda Accord|15 | + |Fremont |Honda CRV |7 | + |Fremont |Honda Civic |10 | + |San Jose|null |13 | + |San Jose|Honda Accord|8 | + |San Jose|Honda Civic |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 |Honda Accord|33 | + |null |Honda CRV |10 | + |null |Honda Civic |35 | + |Dublin |null |33 | + |Dublin |Honda Accord|10 | + |Dublin |Honda CRV |3 | + |Dublin |Honda Civic |20 | + |Fremont |null |32 | + |Fremont |Honda Accord|15 | + |Fremont |Honda CRV |7 | + |Fremont |Honda Civic |10 | + |San Jose|null |13 | + |San Jose|Honda Accord|8 | + |San Jose|Honda Civic |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; + + +--------+------------+---+ + |city |car_model |sum| + +--------+------------+---+ + |null |null |78 | + |Dublin |null |33 | + |Dublin |Honda Accord|10 | + |Dublin |Honda CRV |3 | + |Dublin |Honda Civic |20 | + |Fremont |null |32 | + |Fremont |Honda Accord|15 | + |Fremont |Honda CRV |7 | + |Fremont |Honda Civic |10 | + |San Jose|null |13 | + |San Jose|Honda Accord|8 | + |San Jose|Honda Civic |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; + + +--------+------------+---+ + |city |car_model |sum| + +--------+------------+---+ + |null |null |78 | + |null |Honda Accord|33 | + |null |Honda CRV |10 | + |null |Honda Civic |35 | + |Dublin |null |33 | + |Dublin |Honda Accord|10 | + |Dublin |Honda CRV |3 | + |Dublin |Honda Civic |20 | + |Fremont |null |32 | + |Fremont |Honda Accord|15 | + |Fremont |Honda CRV |7 | + |Fremont |Honda Civic |10 | + |San Jose|null |13 | + |San Jose|Honda Accord|8 | + |San Jose|Honda Civic |5 | + +--------+------------+---+ + +{% endhighlight %}