* cannot do so if the HAVING clause contains aggregates (obviously) or
* volatile functions (since a HAVING clause is supposed to be executed
* only once per group). We also can't do this if there are any nonempty
- * grouping sets; moving such a clause into WHERE would potentially change
- * the results, if any referenced column isn't present in all the grouping
- * sets. (If there are only empty grouping sets, then the HAVING clause
- * must be degenerate as discussed below.)
+ * grouping sets and the clause references any columns that are nullable
+ * by the grouping sets; moving such a clause into WHERE would potentially
+ * change the results. (If there are only empty grouping sets, then the
+ * HAVING clause must be degenerate as discussed below.)
*
* Also, it may be that the clause is so expensive to execute that we're
* better off doing it only once per group, despite the loss of
{
Node *havingclause = (Node *) lfirst(l);
- if ((parse->groupClause && parse->groupingSets) ||
- contain_agg_clause(havingclause) ||
+ if (contain_agg_clause(havingclause) ||
contain_volatile_functions(havingclause) ||
- contain_subplans(havingclause))
+ contain_subplans(havingclause) ||
+ (parse->groupClause && parse->groupingSets &&
+ bms_is_member(root->group_rtindex, pull_varnos(root, havingclause))))
{
/* keep it in HAVING */
newHaving = lappend(newHaving, havingclause);
}
- else if (parse->groupClause && !parse->groupingSets)
+ else if (parse->groupClause)
{
Node *whereclause;
-> Seq Scan on gstest2
(10 rows)
+-- test pushdown of HAVING clause that does not reference any columns that are nullable by grouping sets
+explain (costs off)
+select a, b, count(*) from gstest2 group by grouping sets ((a, b), (a)) having a > 1 and b > 1;
+ QUERY PLAN
+---------------------------------
+ GroupAggregate
+ Group Key: a, b
+ Group Key: a
+ Filter: (b > 1)
+ -> Sort
+ Sort Key: a, b
+ -> Seq Scan on gstest2
+ Filter: (a > 1)
+(8 rows)
+
+select a, b, count(*) from gstest2 group by grouping sets ((a, b), (a)) having a > 1 and b > 1;
+ a | b | count
+---+---+-------
+ 2 | 2 | 1
+(1 row)
+
-- HAVING with GROUPING queries
select ten, grouping(ten) from onek
group by grouping sets(ten) having grouping(ten) >= 0
select v.c, (select count(*) from gstest2 group by () having v.c)
from (values (false),(true)) v(c) order by v.c;
+-- test pushdown of HAVING clause that does not reference any columns that are nullable by grouping sets
+explain (costs off)
+select a, b, count(*) from gstest2 group by grouping sets ((a, b), (a)) having a > 1 and b > 1;
+select a, b, count(*) from gstest2 group by grouping sets ((a, b), (a)) having a > 1 and b > 1;
+
-- HAVING with GROUPING queries
select ten, grouping(ten) from onek
group by grouping sets(ten) having grouping(ten) >= 0