Skip to content

Commit 9660fbe

Browse files
author
Commitfest Bot
committed
[CF 6085] v7 - GROUP BY ALL
This branch was automatically generated by a robot using patches from an email thread registered at: https://commitfest.postgresql.org/patch/6085 The branch will be overwritten each time a new patch version is posted to the thread, and also periodically to check for bitrot caused by changes on the master branch. Patch(es): https://www.postgresql.org/message-id/CAHM0NXjJdKgTC91VegL_SruOBn_PQoeCime_DZkOA02HChPDmw@mail.gmail.com Author(s): David Christensen
2 parents b0fb2c6 + 0138e81 commit 9660fbe

File tree

10 files changed

+300
-4
lines changed

10 files changed

+300
-4
lines changed

doc/src/sgml/queries.sgml

Lines changed: 28 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1151,6 +1151,34 @@ SELECT product_id, p.name, (sum(s.units) * p.price) AS sales
11511151
column names is also allowed.
11521152
</para>
11531153

1154+
<para>
1155+
PostgreSQL also supports the <literal>GROUP BY ALL</literal> syntax, which
1156+
is equivalent to explicitly including all columns or expressions which do
1157+
not contain either an aggregate function or a window function in their
1158+
expression list. This can greatly simplify ad-hoc exploration of data.
1159+
</para>
1160+
1161+
<para>
1162+
An example of the equivalence is this:
1163+
<screen>
1164+
<prompt>=&gt;</prompt> <userinput>SELECT a, b, a + b, sum(c) FROM test1 GROUP BY ALL;</userinput>
1165+
a | b | ?column? | sum
1166+
---+---+----------+----
1167+
1 | 4 | 5 | 9
1168+
2 | 5 | 7 | 12
1169+
3 | 6 | 9 | 15
1170+
(3 rows)
1171+
1172+
<prompt>=&gt;</prompt> <userinput>SELECT a, b, a + b, sum(c) FROM test1 GROUP BY a, b, a + b;</userinput>
1173+
a | b | ?column? | sum
1174+
---+---+----------+----
1175+
1 | 4 | 5 | 9
1176+
2 | 5 | 7 | 12
1177+
3 | 6 | 9 | 15
1178+
(3 rows)
1179+
</screen>
1180+
</para>
1181+
11541182
<indexterm>
11551183
<primary>HAVING</primary>
11561184
</indexterm>

doc/src/sgml/ref/select.sgml

Lines changed: 9 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -796,7 +796,7 @@ WHERE <replaceable class="parameter">condition</replaceable>
796796
<para>
797797
The optional <literal>GROUP BY</literal> clause has the general form
798798
<synopsis>
799-
GROUP BY [ ALL | DISTINCT ] <replaceable class="parameter">grouping_element</replaceable> [, ...]
799+
GROUP BY { ALL | [ ALL | DISTINCT ] <replaceable class="parameter">grouping_element</replaceable> [, ...] }
800800
</synopsis>
801801
</para>
802802

@@ -813,6 +813,14 @@ GROUP BY [ ALL | DISTINCT ] <replaceable class="parameter">grouping_element</rep
813813
input-column name rather than an output column name.
814814
</para>
815815

816+
<para>
817+
The form <literal>GROUP BY ALL</literal> with no additional
818+
<replaceable class="parameter">grouping_element</replaceable> elements
819+
provided is equivalent to doing a <literal>GROUP BY</literal> on all
820+
expressions in the target list that do not contain either an aggregate or
821+
a window function.
822+
</para>
823+
816824
<para>
817825
If any of <literal>GROUPING SETS</literal>, <literal>ROLLUP</literal> or
818826
<literal>CUBE</literal> are present as grouping elements, then the

src/backend/parser/analyze.c

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1467,12 +1467,14 @@ transformSelectStmt(ParseState *pstate, SelectStmt *stmt,
14671467

14681468
qry->groupClause = transformGroupClause(pstate,
14691469
stmt->groupClause,
1470+
stmt->groupByAll,
14701471
&qry->groupingSets,
14711472
&qry->targetList,
14721473
qry->sortClause,
14731474
EXPR_KIND_GROUP_BY,
14741475
false /* allow SQL92 rules */ );
14751476
qry->groupDistinct = stmt->groupDistinct;
1477+
qry->groupByAll = stmt->groupByAll;
14761478

14771479
if (stmt->distinctClause == NIL)
14781480
{

src/backend/parser/gram.y

Lines changed: 14 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -120,6 +120,7 @@ typedef struct SelectLimit
120120
typedef struct GroupClause
121121
{
122122
bool distinct;
123+
bool all;
123124
List *list;
124125
} GroupClause;
125126

@@ -12993,6 +12994,7 @@ simple_select:
1299312994
n->whereClause = $6;
1299412995
n->groupClause = ($7)->list;
1299512996
n->groupDistinct = ($7)->distinct;
12997+
n->groupByAll = ($7)->all;
1299612998
n->havingClause = $8;
1299712999
n->windowClause = $9;
1299813000
$$ = (Node *) n;
@@ -13010,6 +13012,7 @@ simple_select:
1301013012
n->whereClause = $6;
1301113013
n->groupClause = ($7)->list;
1301213014
n->groupDistinct = ($7)->distinct;
13015+
n->groupByAll = ($7)->all;
1301313016
n->havingClause = $8;
1301413017
n->windowClause = $9;
1301513018
$$ = (Node *) n;
@@ -13507,14 +13510,24 @@ group_clause:
1350713510
GroupClause *n = (GroupClause *) palloc(sizeof(GroupClause));
1350813511

1350913512
n->distinct = $3 == SET_QUANTIFIER_DISTINCT;
13513+
n->all = false;
1351013514
n->list = $4;
1351113515
$$ = n;
1351213516
}
13517+
| GROUP_P BY ALL
13518+
{
13519+
GroupClause *n = (GroupClause *) palloc(sizeof(GroupClause));
13520+
n->distinct = false;
13521+
n->all = true;
13522+
n->list = NIL;
13523+
$$ = n;
13524+
}
1351313525
| /*EMPTY*/
1351413526
{
1351513527
GroupClause *n = (GroupClause *) palloc(sizeof(GroupClause));
1351613528

1351713529
n->distinct = false;
13530+
n->all = false;
1351813531
n->list = NIL;
1351913532
$$ = n;
1352013533
}
@@ -17618,6 +17631,7 @@ PLpgSQL_Expr: opt_distinct_clause opt_target_list
1761817631
n->whereClause = $4;
1761917632
n->groupClause = ($5)->list;
1762017633
n->groupDistinct = ($5)->distinct;
17634+
n->groupByAll = ($5)->all;
1762117635
n->havingClause = $6;
1762217636
n->windowClause = $7;
1762317637
n->sortClause = $8;

src/backend/parser/parse_clause.c

Lines changed: 64 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -2598,6 +2598,9 @@ transformGroupingSet(List **flatresult,
25982598
* GROUP BY items will be added to the targetlist (as resjunk columns)
25992599
* if not already present, so the targetlist must be passed by reference.
26002600
*
2601+
* If GROUP BY ALL is specified, the groupClause will be inferred to be all
2602+
* non-aggregate, non-window expressions in the targetlist.
2603+
*
26012604
* This is also used for window PARTITION BY clauses (which act almost the
26022605
* same, but are always interpreted per SQL99 rules).
26032606
*
@@ -2622,14 +2625,16 @@ transformGroupingSet(List **flatresult,
26222625
*
26232626
* pstate ParseState
26242627
* grouplist clause to transform
2628+
* groupByAll is this a GROUP BY ALL statement?
26252629
* groupingSets reference to list to contain the grouping set tree
26262630
* targetlist reference to TargetEntry list
26272631
* sortClause ORDER BY clause (SortGroupClause nodes)
26282632
* exprKind expression kind
26292633
* useSQL99 SQL99 rather than SQL92 syntax
26302634
*/
26312635
List *
2632-
transformGroupClause(ParseState *pstate, List *grouplist, List **groupingSets,
2636+
transformGroupClause(ParseState *pstate, List *grouplist, bool groupByAll,
2637+
List **groupingSets,
26332638
List **targetlist, List *sortClause,
26342639
ParseExprKind exprKind, bool useSQL99)
26352640
{
@@ -2640,6 +2645,63 @@ transformGroupClause(ParseState *pstate, List *grouplist, List **groupingSets,
26402645
bool hasGroupingSets = false;
26412646
Bitmapset *seen_local = NULL;
26422647

2648+
/* Handle GROUP BY ALL */
2649+
if (groupByAll)
2650+
{
2651+
/* There cannot have been any explicit grouplist items */
2652+
Assert(grouplist == NIL);
2653+
2654+
/* Iterate over targets, adding acceptable ones to the result list */
2655+
foreach_ptr(TargetEntry, tle, *targetlist)
2656+
{
2657+
/* Ignore junk TLEs */
2658+
if (tle->resjunk)
2659+
continue;
2660+
2661+
/*
2662+
* TLEs containing aggregates are not okay to add to GROUP BY
2663+
* (compare checkTargetlistEntrySQL92). But the SQL standard
2664+
* directs us to skip them, so it's fine.
2665+
*/
2666+
if (pstate->p_hasAggs &&
2667+
contain_aggs_of_level((Node *) tle->expr, 0))
2668+
continue;
2669+
2670+
/*
2671+
* Likewise, TLEs containing window functions are not okay to add
2672+
* to GROUP BY. At this writing, the SQL standard is silent on
2673+
* what to do with them, but by analogy to aggregates we'll just
2674+
* skip them.
2675+
*/
2676+
if (pstate->p_hasWindowFuncs &&
2677+
contain_windowfuncs((Node *) tle->expr))
2678+
continue;
2679+
2680+
/*
2681+
* Otherwise, add the TLE to the result using default sort/group
2682+
* semantics. We specify the parse location as the TLE's
2683+
* location, despite the comment for addTargetToGroupList
2684+
* discouraging that. The only other thing we could point to is
2685+
* the ALL keyword, which seems unhelpful when there are multiple
2686+
* TLEs.
2687+
*/
2688+
result = addTargetToGroupList(pstate, tle,
2689+
result, *targetlist,
2690+
exprLocation((Node *) tle->expr));
2691+
}
2692+
2693+
/* If we found any acceptable targets, we're done */
2694+
if (result != NIL)
2695+
return result;
2696+
2697+
/*
2698+
* Otherwise, the SQL standard says to treat it like "GROUP BY ()".
2699+
* Build a representation of that, and let the rest of this function
2700+
* handle it.
2701+
*/
2702+
grouplist = list_make1(makeGroupingSet(GROUPING_SET_EMPTY, NIL, -1));
2703+
}
2704+
26432705
/*
26442706
* Recursively flatten implicit RowExprs. (Technically this is only needed
26452707
* for GROUP BY, per the syntax rules for grouping sets, but we do it
@@ -2818,6 +2880,7 @@ transformWindowDefinitions(ParseState *pstate,
28182880
true /* force SQL99 rules */ );
28192881
partitionClause = transformGroupClause(pstate,
28202882
windef->partitionClause,
2883+
false /* not GROUP BY ALL */ ,
28212884
NULL,
28222885
targetlist,
28232886
orderClause,

src/backend/utils/adt/ruleutils.c

Lines changed: 3 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -6186,7 +6186,9 @@ get_basic_select_query(Query *query, deparse_context *context)
61866186
save_ingroupby = context->inGroupBy;
61876187
context->inGroupBy = true;
61886188

6189-
if (query->groupingSets == NIL)
6189+
if (query->groupByAll)
6190+
appendStringInfoString(buf, "ALL");
6191+
else if (query->groupingSets == NIL)
61906192
{
61916193
sep = "";
61926194
foreach(l, query->groupClause)

src/include/nodes/parsenodes.h

Lines changed: 3 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -214,7 +214,8 @@ typedef struct Query
214214
List *returningList; /* return-values list (of TargetEntry) */
215215

216216
List *groupClause; /* a list of SortGroupClause's */
217-
bool groupDistinct; /* is the group by clause distinct? */
217+
bool groupDistinct; /* was GROUP BY DISTINCT used? */
218+
bool groupByAll; /* was GROUP BY ALL used? */
218219

219220
List *groupingSets; /* a list of GroupingSet's if present */
220221

@@ -2192,6 +2193,7 @@ typedef struct SelectStmt
21922193
Node *whereClause; /* WHERE qualification */
21932194
List *groupClause; /* GROUP BY clauses */
21942195
bool groupDistinct; /* Is this GROUP BY DISTINCT? */
2196+
bool groupByAll; /* Is this GROUP BY ALL? */
21952197
Node *havingClause; /* HAVING conditional-expression */
21962198
List *windowClause; /* WINDOW window_name AS (...), ... */
21972199

src/include/parser/parse_clause.h

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -26,6 +26,7 @@ extern Node *transformLimitClause(ParseState *pstate, Node *clause,
2626
ParseExprKind exprKind, const char *constructName,
2727
LimitOption limitOption);
2828
extern List *transformGroupClause(ParseState *pstate, List *grouplist,
29+
bool groupByAll,
2930
List **groupingSets,
3031
List **targetlist, List *sortClause,
3132
ParseExprKind exprKind, bool useSQL99);

src/test/regress/expected/aggregates.out

Lines changed: 122 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1557,6 +1557,128 @@ drop table t2;
15571557
drop table t3;
15581558
drop table p_t1;
15591559
--
1560+
-- Test GROUP BY ALL
1561+
--
1562+
-- We don't care about the data here, just the proper transformation of the
1563+
-- GROUP BY clause, so test some queries and verify the EXPLAIN plans.
1564+
--
1565+
CREATE TEMP TABLE t1 (
1566+
a int,
1567+
b int,
1568+
c int
1569+
);
1570+
-- basic example
1571+
EXPLAIN (COSTS OFF) SELECT b, COUNT(*) FROM t1 GROUP BY ALL;
1572+
QUERY PLAN
1573+
----------------------
1574+
HashAggregate
1575+
Group Key: b
1576+
-> Seq Scan on t1
1577+
(3 rows)
1578+
1579+
-- multiple columns, non-consecutive order
1580+
EXPLAIN (COSTS OFF) SELECT a, SUM(b), b FROM t1 GROUP BY ALL;
1581+
QUERY PLAN
1582+
----------------------
1583+
HashAggregate
1584+
Group Key: a, b
1585+
-> Seq Scan on t1
1586+
(3 rows)
1587+
1588+
-- multi columns, no aggregate
1589+
EXPLAIN (COSTS OFF) SELECT a + b FROM t1 GROUP BY ALL;
1590+
QUERY PLAN
1591+
----------------------
1592+
HashAggregate
1593+
Group Key: (a + b)
1594+
-> Seq Scan on t1
1595+
(3 rows)
1596+
1597+
-- check we detect a non-top-level aggregate
1598+
EXPLAIN (COSTS OFF) SELECT a, SUM(b) + 4 FROM t1 GROUP BY ALL;
1599+
QUERY PLAN
1600+
----------------------
1601+
HashAggregate
1602+
Group Key: a
1603+
-> Seq Scan on t1
1604+
(3 rows)
1605+
1606+
-- including grouped column is okay
1607+
EXPLAIN (COSTS OFF) SELECT a, SUM(b) + a FROM t1 GROUP BY ALL;
1608+
QUERY PLAN
1609+
----------------------
1610+
HashAggregate
1611+
Group Key: a
1612+
-> Seq Scan on t1
1613+
(3 rows)
1614+
1615+
-- including non-grouped column, not so much
1616+
EXPLAIN (COSTS OFF) SELECT a, SUM(b) + c FROM t1 GROUP BY ALL;
1617+
ERROR: column "t1.c" must appear in the GROUP BY clause or be used in an aggregate function
1618+
LINE 1: EXPLAIN (COSTS OFF) SELECT a, SUM(b) + c FROM t1 GROUP BY AL...
1619+
^
1620+
-- all aggregates, should reduce to GROUP BY ()
1621+
EXPLAIN (COSTS OFF) SELECT COUNT(a), SUM(b) FROM t1 GROUP BY ALL;
1622+
QUERY PLAN
1623+
----------------------
1624+
Aggregate
1625+
Group Key: ()
1626+
-> Seq Scan on t1
1627+
(3 rows)
1628+
1629+
-- likewise with empty target list
1630+
EXPLAIN (COSTS OFF) SELECT FROM t1 GROUP BY ALL;
1631+
QUERY PLAN
1632+
-----------------------
1633+
Result
1634+
Replaces: Aggregate
1635+
(2 rows)
1636+
1637+
-- window functions are not to be included in GROUP BY, either
1638+
EXPLAIN (COSTS OFF) SELECT a, COUNT(a) OVER (PARTITION BY a) FROM t1 GROUP BY ALL;
1639+
QUERY PLAN
1640+
----------------------------------
1641+
WindowAgg
1642+
Window: w1 AS (PARTITION BY a)
1643+
-> Sort
1644+
Sort Key: a
1645+
-> HashAggregate
1646+
Group Key: a
1647+
-> Seq Scan on t1
1648+
(7 rows)
1649+
1650+
-- all cols
1651+
EXPLAIN (COSTS OFF) SELECT *, count(*) FROM t1 GROUP BY ALL;
1652+
QUERY PLAN
1653+
----------------------
1654+
HashAggregate
1655+
Group Key: a, b, c
1656+
-> Seq Scan on t1
1657+
(3 rows)
1658+
1659+
-- group by all but with column lists (equivalent to GROUP BY default behavior, explicit antithesis to GROUP BY DISTINCT)
1660+
EXPLAIN (COSTS OFF) SELECT a, count(*) FROM t1 GROUP BY ALL a;
1661+
QUERY PLAN
1662+
----------------------
1663+
HashAggregate
1664+
Group Key: a
1665+
-> Seq Scan on t1
1666+
(3 rows)
1667+
1668+
-- verify deparsing of GROUP BY ALL
1669+
CREATE TEMP VIEW v1 AS SELECT b, COUNT(*) FROM t1 GROUP BY ALL;
1670+
SELECT pg_get_viewdef('v1'::regclass);
1671+
pg_get_viewdef
1672+
-----------------------
1673+
SELECT b, +
1674+
count(*) AS count+
1675+
FROM t1 +
1676+
GROUP BY ALL;
1677+
(1 row)
1678+
1679+
DROP VIEW v1;
1680+
DROP TABLE t1;
1681+
--
15601682
-- Test GROUP BY matching of join columns that are type-coerced due to USING
15611683
--
15621684
create temp table t1(f1 int, f2 int);

0 commit comments

Comments
 (0)