* Inside a grouping set (ROLLUP, CUBE, or GROUPING SETS), we expect the
* content to be nested no more than 2 deep: i.e. ROLLUP((a,b),(c,d)) is
* ok, but ROLLUP((a,(b,c)),d) is flattened to ((a,b,c),d), which we then
- * normalize to ((a,b,c),(d)).
+ * (later) normalize to ((a,b,c),(d)).
*
* CUBE or ROLLUP can be nested inside GROUPING SETS (but not the reverse),
* and we leave that alone if we find it. But if we see GROUPING SETS inside
foreach(l2, gset->content)
{
- Node *n2 = flatten_grouping_sets(lfirst(l2), false, NULL);
+ Node *n1 = lfirst(l2);
+ Node *n2 = flatten_grouping_sets(n1, false, NULL);
- result_set = lappend(result_set, n2);
+ if (IsA(n1, GroupingSet) &&
+ ((GroupingSet *)n1)->kind == GROUPING_SET_SETS)
+ {
+ result_set = list_concat(result_set, (List *) n2);
+ }
+ else
+ result_set = lappend(result_set, n2);
}
/*
| | 12 | 36
(6 rows)
+-- nesting with grouping sets
+select sum(c) from gstest2
+ group by grouping sets((), grouping sets((), grouping sets(())))
+ order by 1 desc;
+ sum
+-----
+ 12
+ 12
+ 12
+(3 rows)
+
+select sum(c) from gstest2
+ group by grouping sets((), grouping sets((), grouping sets(((a, b)))))
+ order by 1 desc;
+ sum
+-----
+ 12
+ 12
+ 8
+ 2
+ 2
+(5 rows)
+
+select sum(c) from gstest2
+ group by grouping sets(grouping sets(rollup(c), grouping sets(cube(c))))
+ order by 1 desc;
+ sum
+-----
+ 12
+ 12
+ 6
+ 6
+ 6
+ 6
+(6 rows)
+
+select sum(c) from gstest2
+ group by grouping sets(a, grouping sets(a, cube(b)))
+ order by 1 desc;
+ sum
+-----
+ 12
+ 10
+ 10
+ 8
+ 4
+ 2
+ 2
+(7 rows)
+
+select sum(c) from gstest2
+ group by grouping sets(grouping sets((a, (b))))
+ order by 1 desc;
+ sum
+-----
+ 8
+ 2
+ 2
+(3 rows)
+
+select sum(c) from gstest2
+ group by grouping sets(grouping sets((a, b)))
+ order by 1 desc;
+ sum
+-----
+ 8
+ 2
+ 2
+(3 rows)
+
+select sum(c) from gstest2
+ group by grouping sets(grouping sets(a, grouping sets(a), a))
+ order by 1 desc;
+ sum
+-----
+ 10
+ 10
+ 10
+ 2
+ 2
+ 2
+(6 rows)
+
+select sum(c) from gstest2
+ group by grouping sets(grouping sets(a, grouping sets(a, grouping sets(a), ((a)), a, grouping sets(a), (a)), a))
+ order by 1 desc;
+ sum
+-----
+ 10
+ 10
+ 10
+ 10
+ 10
+ 10
+ 10
+ 10
+ 2
+ 2
+ 2
+ 2
+ 2
+ 2
+ 2
+ 2
+(16 rows)
+
+select sum(c) from gstest2
+ group by grouping sets((a,(a,b)), grouping sets((a,(a,b)),a))
+ order by 1 desc;
+ sum
+-----
+ 10
+ 8
+ 8
+ 2
+ 2
+ 2
+ 2
+ 2
+(8 rows)
+
-- empty input: first is 0 rows, second 1, third 3 etc.
select a, b, sum(v), count(*) from gstest_empty group by grouping sets ((a,b),a);
a | b | sum | count
select a, b, sum(c), sum(sum(c)) over (order by a,b) as rsum
from gstest2 group by rollup (a,b) order by rsum, a, b;
+-- nesting with grouping sets
+select sum(c) from gstest2
+ group by grouping sets((), grouping sets((), grouping sets(())))
+ order by 1 desc;
+select sum(c) from gstest2
+ group by grouping sets((), grouping sets((), grouping sets(((a, b)))))
+ order by 1 desc;
+select sum(c) from gstest2
+ group by grouping sets(grouping sets(rollup(c), grouping sets(cube(c))))
+ order by 1 desc;
+select sum(c) from gstest2
+ group by grouping sets(a, grouping sets(a, cube(b)))
+ order by 1 desc;
+select sum(c) from gstest2
+ group by grouping sets(grouping sets((a, (b))))
+ order by 1 desc;
+select sum(c) from gstest2
+ group by grouping sets(grouping sets((a, b)))
+ order by 1 desc;
+select sum(c) from gstest2
+ group by grouping sets(grouping sets(a, grouping sets(a), a))
+ order by 1 desc;
+select sum(c) from gstest2
+ group by grouping sets(grouping sets(a, grouping sets(a, grouping sets(a), ((a)), a, grouping sets(a), (a)), a))
+ order by 1 desc;
+select sum(c) from gstest2
+ group by grouping sets((a,(a,b)), grouping sets((a,(a,b)),a))
+ order by 1 desc;
+
-- empty input: first is 0 rows, second 1, third 3 etc.
select a, b, sum(v), count(*) from gstest_empty group by grouping sets ((a,b),a);
select a, b, sum(v), count(*) from gstest_empty group by grouping sets ((a,b),());