diff options
Diffstat (limited to 'src/test')
| -rw-r--r-- | src/test/regress/expected/groupingsets.out | 616 | ||||
| -rw-r--r-- | src/test/regress/expected/tsrf.out | 50 | ||||
| -rw-r--r-- | src/test/regress/sql/groupingsets.sql | 155 | ||||
| -rw-r--r-- | src/test/regress/sql/tsrf.sql | 2 |
4 files changed, 791 insertions, 32 deletions
diff --git a/src/test/regress/expected/groupingsets.out b/src/test/regress/expected/groupingsets.out index b0886da8d70..1374710087b 100644 --- a/src/test/regress/expected/groupingsets.out +++ b/src/test/regress/expected/groupingsets.out @@ -13,6 +13,13 @@ copy gstest2 from stdin; create temp table gstest3 (a integer, b integer, c integer, d integer); copy gstest3 from stdin; alter table gstest3 add primary key (a); +create temp table gstest4(id integer, v integer, + unhashable_col bit(4), unsortable_col xid); +insert into gstest4 +values (1,1,b'0000','1'), (2,2,b'0001','1'), + (3,4,b'0010','2'), (4,8,b'0011','2'), + (5,16,b'0000','2'), (6,32,b'0001','2'), + (7,64,b'0010','1'), (8,128,b'0011','1'); create temp table gstest_empty (a integer, b integer, v integer); create function gstest_data(v integer, out a integer, out b integer) returns setof record @@ -22,6 +29,7 @@ create function gstest_data(v integer, out a integer, out b integer) end; $f$ language plpgsql; -- basic functionality +set enable_hashagg = false; -- test hashing explicitly later -- simple rollup with multiple plain aggregates, with and without ordering -- (and with ordering differing from grouping) select a, b, grouping(a,b), sum(v), count(*), max(v) @@ -462,7 +470,7 @@ select a, b from (values (1,2),(2,3)) v(a,b) group by a,b, grouping sets(a); -- Tests for chained aggregates select a, b, grouping(a,b), sum(v), count(*), max(v) - from gstest1 group by grouping sets ((a,b),(a+1,b+1),(a+2,b+2)); + from gstest1 group by grouping sets ((a,b),(a+1,b+1),(a+2,b+2)) order by 3,6; a | b | grouping | sum | count | max ---+---+----------+-----+-------+----- 1 | 1 | 0 | 21 | 2 | 11 @@ -473,19 +481,19 @@ select a, b, grouping(a,b), sum(v), count(*), max(v) 3 | 4 | 0 | 17 | 1 | 17 4 | 1 | 0 | 37 | 2 | 19 | | 3 | 21 | 2 | 11 - | | 3 | 25 | 2 | 13 - | | 3 | 14 | 1 | 14 - | | 3 | 15 | 1 | 15 - | | 3 | 16 | 1 | 16 - | | 3 | 17 | 1 | 17 - | | 3 | 37 | 2 | 19 | | 3 | 21 | 2 | 11 | | 3 | 25 | 2 | 13 + | | 3 | 25 | 2 | 13 + | | 3 | 14 | 1 | 14 | | 3 | 14 | 1 | 14 | | 3 | 15 | 1 | 15 + | | 3 | 15 | 1 | 15 | | 3 | 16 | 1 | 16 + | | 3 | 16 | 1 | 16 + | | 3 | 17 | 1 | 17 | | 3 | 17 | 1 | 17 | | 3 | 37 | 2 | 19 + | | 3 | 37 | 2 | 19 (21 rows) select(select (select grouping(a,b) from (values (1)) v2(c)) from (values (1,2)) v1(a,b) group by (a,b)) from (values(6,7)) v3(e,f) GROUP BY ROLLUP((e+1),(f+1)); @@ -847,4 +855,598 @@ select sum(ten) from onek group by rollup(four::text), two order by 1; 2500 (6 rows) +-- hashing support +set enable_hashagg = true; +-- failure cases +select count(*) from gstest4 group by rollup(unhashable_col,unsortable_col); +ERROR: could not implement GROUP BY +DETAIL: Some of the datatypes only support hashing, while others only support sorting. +select array_agg(v order by v) from gstest4 group by grouping sets ((id,unsortable_col),(id)); +ERROR: could not implement GROUP BY +DETAIL: Some of the datatypes only support hashing, while others only support sorting. +-- simple cases +select a, b, grouping(a,b), sum(v), count(*), max(v) + from gstest1 group by grouping sets ((a),(b)) order by 3,1,2; + a | b | grouping | sum | count | max +---+---+----------+-----+-------+----- + 1 | | 1 | 60 | 5 | 14 + 2 | | 1 | 15 | 1 | 15 + 3 | | 1 | 33 | 2 | 17 + 4 | | 1 | 37 | 2 | 19 + | 1 | 2 | 58 | 4 | 19 + | 2 | 2 | 25 | 2 | 13 + | 3 | 2 | 45 | 3 | 16 + | 4 | 2 | 17 | 1 | 17 +(8 rows) + +explain (costs off) select a, b, grouping(a,b), sum(v), count(*), max(v) + from gstest1 group by grouping sets ((a),(b)) order by 3,1,2; + QUERY PLAN +-------------------------------------------------------------------------------------------------------- + Sort + Sort Key: (GROUPING("*VALUES*".column1, "*VALUES*".column2)), "*VALUES*".column1, "*VALUES*".column2 + -> HashAggregate + Hash Key: "*VALUES*".column1 + Hash Key: "*VALUES*".column2 + -> Values Scan on "*VALUES*" +(6 rows) + +select a, b, grouping(a,b), sum(v), count(*), max(v) + from gstest1 group by cube(a,b) order by 3,1,2; + a | b | grouping | sum | count | max +---+---+----------+-----+-------+----- + 1 | 1 | 0 | 21 | 2 | 11 + 1 | 2 | 0 | 25 | 2 | 13 + 1 | 3 | 0 | 14 | 1 | 14 + 2 | 3 | 0 | 15 | 1 | 15 + 3 | 3 | 0 | 16 | 1 | 16 + 3 | 4 | 0 | 17 | 1 | 17 + 4 | 1 | 0 | 37 | 2 | 19 + 1 | | 1 | 60 | 5 | 14 + 2 | | 1 | 15 | 1 | 15 + 3 | | 1 | 33 | 2 | 17 + 4 | | 1 | 37 | 2 | 19 + | 1 | 2 | 58 | 4 | 19 + | 2 | 2 | 25 | 2 | 13 + | 3 | 2 | 45 | 3 | 16 + | 4 | 2 | 17 | 1 | 17 + | | 3 | 145 | 10 | 19 +(16 rows) + +explain (costs off) select a, b, grouping(a,b), sum(v), count(*), max(v) + from gstest1 group by cube(a,b) order by 3,1,2; + QUERY PLAN +-------------------------------------------------------------------------------------------------------- + Sort + Sort Key: (GROUPING("*VALUES*".column1, "*VALUES*".column2)), "*VALUES*".column1, "*VALUES*".column2 + -> MixedAggregate + Hash Key: "*VALUES*".column1, "*VALUES*".column2 + Hash Key: "*VALUES*".column1 + Hash Key: "*VALUES*".column2 + Group Key: () + -> Values Scan on "*VALUES*" +(8 rows) + +-- shouldn't try and hash +explain (costs off) + select a, b, grouping(a,b), array_agg(v order by v) + from gstest1 group by cube(a,b); + QUERY PLAN +---------------------------------------------------------- + GroupAggregate + Group Key: "*VALUES*".column1, "*VALUES*".column2 + Group Key: "*VALUES*".column1 + Group Key: () + Sort Key: "*VALUES*".column2 + Group Key: "*VALUES*".column2 + -> Sort + Sort Key: "*VALUES*".column1, "*VALUES*".column2 + -> Values Scan on "*VALUES*" +(9 rows) + +-- mixed hashable/sortable cases +select unhashable_col, unsortable_col, + grouping(unhashable_col, unsortable_col), + count(*), sum(v) + from gstest4 group by grouping sets ((unhashable_col),(unsortable_col)) + order by 3, 5; + unhashable_col | unsortable_col | grouping | count | sum +----------------+----------------+----------+-------+----- + 0000 | | 1 | 2 | 17 + 0001 | | 1 | 2 | 34 + 0010 | | 1 | 2 | 68 + 0011 | | 1 | 2 | 136 + | 2 | 2 | 4 | 60 + | 1 | 2 | 4 | 195 +(6 rows) + +explain (costs off) + select unhashable_col, unsortable_col, + grouping(unhashable_col, unsortable_col), + count(*), sum(v) + from gstest4 group by grouping sets ((unhashable_col),(unsortable_col)) + order by 3,5; + QUERY PLAN +------------------------------------------------------------------ + Sort + Sort Key: (GROUPING(unhashable_col, unsortable_col)), (sum(v)) + -> MixedAggregate + Hash Key: unsortable_col + Group Key: unhashable_col + -> Sort + Sort Key: unhashable_col + -> Seq Scan on gstest4 +(8 rows) + +select unhashable_col, unsortable_col, + grouping(unhashable_col, unsortable_col), + count(*), sum(v) + from gstest4 group by grouping sets ((v,unhashable_col),(v,unsortable_col)) + order by 3,5; + unhashable_col | unsortable_col | grouping | count | sum +----------------+----------------+----------+-------+----- + 0000 | | 1 | 1 | 1 + 0001 | | 1 | 1 | 2 + 0010 | | 1 | 1 | 4 + 0011 | | 1 | 1 | 8 + 0000 | | 1 | 1 | 16 + 0001 | | 1 | 1 | 32 + 0010 | | 1 | 1 | 64 + 0011 | | 1 | 1 | 128 + | 1 | 2 | 1 | 1 + | 1 | 2 | 1 | 2 + | 2 | 2 | 1 | 4 + | 2 | 2 | 1 | 8 + | 2 | 2 | 1 | 16 + | 2 | 2 | 1 | 32 + | 1 | 2 | 1 | 64 + | 1 | 2 | 1 | 128 +(16 rows) + +explain (costs off) + select unhashable_col, unsortable_col, + grouping(unhashable_col, unsortable_col), + count(*), sum(v) + from gstest4 group by grouping sets ((v,unhashable_col),(v,unsortable_col)) + order by 3,5; + QUERY PLAN +------------------------------------------------------------------ + Sort + Sort Key: (GROUPING(unhashable_col, unsortable_col)), (sum(v)) + -> MixedAggregate + Hash Key: v, unsortable_col + Group Key: v, unhashable_col + -> Sort + Sort Key: v, unhashable_col + -> Seq Scan on gstest4 +(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 +---+---+-----+------- +(0 rows) + +explain (costs off) + select a, b, sum(v), count(*) from gstest_empty group by grouping sets ((a,b),a); + QUERY PLAN +-------------------------------- + HashAggregate + Hash Key: a, b + Hash Key: a + -> Seq Scan on gstest_empty +(4 rows) + +select a, b, sum(v), count(*) from gstest_empty group by grouping sets ((a,b),()); + a | b | sum | count +---+---+-----+------- + | | | 0 +(1 row) + +select a, b, sum(v), count(*) from gstest_empty group by grouping sets ((a,b),(),(),()); + a | b | sum | count +---+---+-----+------- + | | | 0 + | | | 0 + | | | 0 +(3 rows) + +explain (costs off) + select a, b, sum(v), count(*) from gstest_empty group by grouping sets ((a,b),(),(),()); + QUERY PLAN +-------------------------------- + MixedAggregate + Hash Key: a, b + Group Key: () + Group Key: () + Group Key: () + -> Seq Scan on gstest_empty +(6 rows) + +select sum(v), count(*) from gstest_empty group by grouping sets ((),(),()); + sum | count +-----+------- + | 0 + | 0 + | 0 +(3 rows) + +explain (costs off) + select sum(v), count(*) from gstest_empty group by grouping sets ((),(),()); + QUERY PLAN +-------------------------------- + Aggregate + Group Key: () + Group Key: () + Group Key: () + -> Seq Scan on gstest_empty +(5 rows) + +-- check that functionally dependent cols are not nulled +select a, d, grouping(a,b,c) + from gstest3 + group by grouping sets ((a,b), (a,c)); + a | d | grouping +---+---+---------- + 1 | 1 | 1 + 2 | 2 | 1 + 1 | 1 | 2 + 2 | 2 | 2 +(4 rows) + +explain (costs off) + select a, d, grouping(a,b,c) + from gstest3 + group by grouping sets ((a,b), (a,c)); + QUERY PLAN +--------------------------- + HashAggregate + Hash Key: a, b + Hash Key: a, c + -> Seq Scan on gstest3 +(4 rows) + +-- simple rescan tests +select a, b, sum(v.x) + from (values (1),(2)) v(x), gstest_data(v.x) + group by grouping sets (a,b); + a | b | sum +---+---+----- + 2 | | 6 + 1 | | 3 + | 2 | 3 + | 3 | 3 + | 1 | 3 +(5 rows) + +explain (costs off) + select a, b, sum(v.x) + from (values (1),(2)) v(x), gstest_data(v.x) + group by grouping sets (a,b); + QUERY PLAN +------------------------------------------ + HashAggregate + Hash Key: gstest_data.a + Hash Key: gstest_data.b + -> Nested Loop + -> Values Scan on "*VALUES*" + -> Function Scan on gstest_data +(6 rows) + +select * + from (values (1),(2)) v(x), + lateral (select a, b, sum(v.x) from gstest_data(v.x) group by grouping sets (a,b)) s; +ERROR: aggregate functions are not allowed in FROM clause of their own query level +LINE 3: lateral (select a, b, sum(v.x) from gstest_data(v.x) ... + ^ +explain (costs off) + select * + from (values (1),(2)) v(x), + lateral (select a, b, sum(v.x) from gstest_data(v.x) group by grouping sets (a,b)) s; +ERROR: aggregate functions are not allowed in FROM clause of their own query level +LINE 4: lateral (select a, b, sum(v.x) from gstest_data(v.x... + ^ +-- Tests for chained aggregates +select a, b, grouping(a,b), sum(v), count(*), max(v) + from gstest1 group by grouping sets ((a,b),(a+1,b+1),(a+2,b+2)) order by 3,6; + a | b | grouping | sum | count | max +---+---+----------+-----+-------+----- + 1 | 1 | 0 | 21 | 2 | 11 + 1 | 2 | 0 | 25 | 2 | 13 + 1 | 3 | 0 | 14 | 1 | 14 + 2 | 3 | 0 | 15 | 1 | 15 + 3 | 3 | 0 | 16 | 1 | 16 + 3 | 4 | 0 | 17 | 1 | 17 + 4 | 1 | 0 | 37 | 2 | 19 + | | 3 | 21 | 2 | 11 + | | 3 | 21 | 2 | 11 + | | 3 | 25 | 2 | 13 + | | 3 | 25 | 2 | 13 + | | 3 | 14 | 1 | 14 + | | 3 | 14 | 1 | 14 + | | 3 | 15 | 1 | 15 + | | 3 | 15 | 1 | 15 + | | 3 | 16 | 1 | 16 + | | 3 | 16 | 1 | 16 + | | 3 | 17 | 1 | 17 + | | 3 | 17 | 1 | 17 + | | 3 | 37 | 2 | 19 + | | 3 | 37 | 2 | 19 +(21 rows) + +explain (costs off) + select a, b, grouping(a,b), sum(v), count(*), max(v) + from gstest1 group by grouping sets ((a,b),(a+1,b+1),(a+2,b+2)) order by 3,6; + QUERY PLAN +------------------------------------------------------------------------------------------- + Sort + Sort Key: (GROUPING("*VALUES*".column1, "*VALUES*".column2)), (max("*VALUES*".column3)) + -> HashAggregate + Hash Key: "*VALUES*".column1, "*VALUES*".column2 + Hash Key: ("*VALUES*".column1 + 1), ("*VALUES*".column2 + 1) + Hash Key: ("*VALUES*".column1 + 2), ("*VALUES*".column2 + 2) + -> Values Scan on "*VALUES*" +(7 rows) + +select a, b, sum(c), sum(sum(c)) over (order by a,b) as rsum + from gstest2 group by cube (a,b) order by rsum, a, b; + a | b | sum | rsum +---+---+-----+------ + 1 | 1 | 8 | 8 + 1 | 2 | 2 | 10 + 1 | | 10 | 20 + 2 | 2 | 2 | 22 + 2 | | 2 | 24 + | 1 | 8 | 32 + | 2 | 4 | 36 + | | 12 | 48 +(8 rows) + +explain (costs off) + select a, b, sum(c), sum(sum(c)) over (order by a,b) as rsum + from gstest2 group by cube (a,b) order by rsum, a, b; + QUERY PLAN +--------------------------------------------- + Sort + Sort Key: (sum((sum(c))) OVER (?)), a, b + -> WindowAgg + -> Sort + Sort Key: a, b + -> MixedAggregate + Hash Key: a, b + Hash Key: a + Hash Key: b + Group Key: () + -> Seq Scan on gstest2 +(11 rows) + +select a, b, sum(v.x) + from (values (1),(2)) v(x), gstest_data(v.x) + group by cube (a,b) order by a,b; + a | b | sum +---+---+----- + 1 | 1 | 1 + 1 | 2 | 1 + 1 | 3 | 1 + 1 | | 3 + 2 | 1 | 2 + 2 | 2 | 2 + 2 | 3 | 2 + 2 | | 6 + | 1 | 3 + | 2 | 3 + | 3 | 3 + | | 9 +(12 rows) + +explain (costs off) + select a, b, sum(v.x) + from (values (1),(2)) v(x), gstest_data(v.x) + group by cube (a,b) order by a,b; + QUERY PLAN +------------------------------------------------ + Sort + Sort Key: gstest_data.a, gstest_data.b + -> MixedAggregate + Hash Key: gstest_data.a, gstest_data.b + Hash Key: gstest_data.a + Hash Key: gstest_data.b + Group Key: () + -> Nested Loop + -> Values Scan on "*VALUES*" + -> Function Scan on gstest_data +(10 rows) + +-- More rescan tests +select * from (values (1),(2)) v(a) left join lateral (select v.a, four, ten, count(*) from onek group by cube(four,ten)) s on true order by v.a,four,ten; + a | a | four | ten | count +---+---+------+-----+------- + 1 | 1 | 0 | 0 | 50 + 1 | 1 | 0 | 2 | 50 + 1 | 1 | 0 | 4 | 50 + 1 | 1 | 0 | 6 | 50 + 1 | 1 | 0 | 8 | 50 + 1 | 1 | 0 | | 250 + 1 | 1 | 1 | 1 | 50 + 1 | 1 | 1 | 3 | 50 + 1 | 1 | 1 | 5 | 50 + 1 | 1 | 1 | 7 | 50 + 1 | 1 | 1 | 9 | 50 + 1 | 1 | 1 | | 250 + 1 | 1 | 2 | 0 | 50 + 1 | 1 | 2 | 2 | 50 + 1 | 1 | 2 | 4 | 50 + 1 | 1 | 2 | 6 | 50 + 1 | 1 | 2 | 8 | 50 + 1 | 1 | 2 | | 250 + 1 | 1 | 3 | 1 | 50 + 1 | 1 | 3 | 3 | 50 + 1 | 1 | 3 | 5 | 50 + 1 | 1 | 3 | 7 | 50 + 1 | 1 | 3 | 9 | 50 + 1 | 1 | 3 | | 250 + 1 | 1 | | 0 | 100 + 1 | 1 | | 1 | 100 + 1 | 1 | | 2 | 100 + 1 | 1 | | 3 | 100 + 1 | 1 | | 4 | 100 + 1 | 1 | | 5 | 100 + 1 | 1 | | 6 | 100 + 1 | 1 | | 7 | 100 + 1 | 1 | | 8 | 100 + 1 | 1 | | 9 | 100 + 1 | 1 | | | 1000 + 2 | 2 | 0 | 0 | 50 + 2 | 2 | 0 | 2 | 50 + 2 | 2 | 0 | 4 | 50 + 2 | 2 | 0 | 6 | 50 + 2 | 2 | 0 | 8 | 50 + 2 | 2 | 0 | | 250 + 2 | 2 | 1 | 1 | 50 + 2 | 2 | 1 | 3 | 50 + 2 | 2 | 1 | 5 | 50 + 2 | 2 | 1 | 7 | 50 + 2 | 2 | 1 | 9 | 50 + 2 | 2 | 1 | | 250 + 2 | 2 | 2 | 0 | 50 + 2 | 2 | 2 | 2 | 50 + 2 | 2 | 2 | 4 | 50 + 2 | 2 | 2 | 6 | 50 + 2 | 2 | 2 | 8 | 50 + 2 | 2 | 2 | | 250 + 2 | 2 | 3 | 1 | 50 + 2 | 2 | 3 | 3 | 50 + 2 | 2 | 3 | 5 | 50 + 2 | 2 | 3 | 7 | 50 + 2 | 2 | 3 | 9 | 50 + 2 | 2 | 3 | | 250 + 2 | 2 | | 0 | 100 + 2 | 2 | | 1 | 100 + 2 | 2 | | 2 | 100 + 2 | 2 | | 3 | 100 + 2 | 2 | | 4 | 100 + 2 | 2 | | 5 | 100 + 2 | 2 | | 6 | 100 + 2 | 2 | | 7 | 100 + 2 | 2 | | 8 | 100 + 2 | 2 | | 9 | 100 + 2 | 2 | | | 1000 +(70 rows) + +select array(select row(v.a,s1.*) from (select two,four, count(*) from onek group by cube(two,four) order by two,four) s1) from (values (1),(2)) v(a); + array +------------------------------------------------------------------------------------------------------------------------------------------------------ + {"(1,0,0,250)","(1,0,2,250)","(1,0,,500)","(1,1,1,250)","(1,1,3,250)","(1,1,,500)","(1,,0,250)","(1,,1,250)","(1,,2,250)","(1,,3,250)","(1,,,1000)"} + {"(2,0,0,250)","(2,0,2,250)","(2,0,,500)","(2,1,1,250)","(2,1,3,250)","(2,1,,500)","(2,,0,250)","(2,,1,250)","(2,,2,250)","(2,,3,250)","(2,,,1000)"} +(2 rows) + +-- Rescan logic changes when there are no empty grouping sets, so test +-- that too: +select * from (values (1),(2)) v(a) left join lateral (select v.a, four, ten, count(*) from onek group by grouping sets(four,ten)) s on true order by v.a,four,ten; + a | a | four | ten | count +---+---+------+-----+------- + 1 | 1 | 0 | | 250 + 1 | 1 | 1 | | 250 + 1 | 1 | 2 | | 250 + 1 | 1 | 3 | | 250 + 1 | 1 | | 0 | 100 + 1 | 1 | | 1 | 100 + 1 | 1 | | 2 | 100 + 1 | 1 | | 3 | 100 + 1 | 1 | | 4 | 100 + 1 | 1 | | 5 | 100 + 1 | 1 | | 6 | 100 + 1 | 1 | | 7 | 100 + 1 | 1 | | 8 | 100 + 1 | 1 | | 9 | 100 + 2 | 2 | 0 | | 250 + 2 | 2 | 1 | | 250 + 2 | 2 | 2 | | 250 + 2 | 2 | 3 | | 250 + 2 | 2 | | 0 | 100 + 2 | 2 | | 1 | 100 + 2 | 2 | | 2 | 100 + 2 | 2 | | 3 | 100 + 2 | 2 | | 4 | 100 + 2 | 2 | | 5 | 100 + 2 | 2 | | 6 | 100 + 2 | 2 | | 7 | 100 + 2 | 2 | | 8 | 100 + 2 | 2 | | 9 | 100 +(28 rows) + +select array(select row(v.a,s1.*) from (select two,four, count(*) from onek group by grouping sets(two,four) order by two,four) s1) from (values (1),(2)) v(a); + array +--------------------------------------------------------------------------------- + {"(1,0,,500)","(1,1,,500)","(1,,0,250)","(1,,1,250)","(1,,2,250)","(1,,3,250)"} + {"(2,0,,500)","(2,1,,500)","(2,,0,250)","(2,,1,250)","(2,,2,250)","(2,,3,250)"} +(2 rows) + +-- test the knapsack +set work_mem = '64kB'; +explain (costs off) + select unique1, + count(two), count(four), count(ten), + count(hundred), count(thousand), count(twothousand), + count(*) + from tenk1 group by grouping sets (unique1,twothousand,thousand,hundred,ten,four,two); + QUERY PLAN +------------------------------- + MixedAggregate + Hash Key: two + Hash Key: four + Hash Key: ten + Hash Key: hundred + Group Key: unique1 + Sort Key: twothousand + Group Key: twothousand + Sort Key: thousand + Group Key: thousand + -> Sort + Sort Key: unique1 + -> Seq Scan on tenk1 +(13 rows) + +explain (costs off) + select unique1, + count(two), count(four), count(ten), + count(hundred), count(thousand), count(twothousand), + count(*) + from tenk1 group by grouping sets (unique1,hundred,ten,four,two); + QUERY PLAN +------------------------------- + MixedAggregate + Hash Key: two + Hash Key: four + Hash Key: ten + Hash Key: hundred + Group Key: unique1 + -> Sort + Sort Key: unique1 + -> Seq Scan on tenk1 +(9 rows) + +set work_mem = '384kB'; +explain (costs off) + select unique1, + count(two), count(four), count(ten), + count(hundred), count(thousand), count(twothousand), + count(*) + from tenk1 group by grouping sets (unique1,twothousand,thousand,hundred,ten,four,two); + QUERY PLAN +------------------------------- + MixedAggregate + Hash Key: two + Hash Key: four + Hash Key: ten + Hash Key: hundred + Hash Key: thousand + Group Key: unique1 + Sort Key: twothousand + Group Key: twothousand + -> Sort + Sort Key: unique1 + -> Seq Scan on tenk1 +(12 rows) + -- end diff --git a/src/test/regress/expected/tsrf.out b/src/test/regress/expected/tsrf.out index 0eeaf9e8300..33f370b4949 100644 --- a/src/test/regress/expected/tsrf.out +++ b/src/test/regress/expected/tsrf.out @@ -233,6 +233,7 @@ SELECT few.dataa, count(*), min(id), max(id), generate_series(1,3) FROM few GROU (6 rows) -- grouping sets are a bit special, they produce NULLs in columns not actually NULL +set enable_hashagg = false; SELECT dataa, datab b, generate_series(1,2) g, count(*) FROM few GROUP BY CUBE(dataa, datab); dataa | b | g | count -------+-----+---+------- @@ -311,46 +312,46 @@ SELECT dataa, datab b, generate_series(1,2) g, count(*) FROM few GROUP BY CUBE(d b | bar | | 2 b | | | 2 | | | 6 - a | | 1 | 2 - b | | 1 | 1 - | | 1 | 3 - a | | 2 | 2 - b | | 2 | 1 - | | 2 | 3 | bar | 1 | 2 | bar | 2 | 2 | bar | | 4 | foo | 1 | 1 | foo | 2 | 1 | foo | | 2 + a | | 1 | 2 + b | | 1 | 1 + | | 1 | 3 + a | | 2 | 2 + b | | 2 | 1 + | | 2 | 3 (24 rows) SELECT dataa, datab b, generate_series(1,2) g, count(*) FROM few GROUP BY CUBE(dataa, datab, g) ORDER BY dataa; dataa | b | g | count -------+-----+---+------- + a | foo | | 2 + a | | | 4 + a | | 2 | 2 a | bar | 1 | 1 a | bar | 2 | 1 a | bar | | 2 a | foo | 1 | 1 a | foo | 2 | 1 - a | foo | | 2 - a | | | 4 a | | 1 | 2 - a | | 2 | 2 - b | bar | 2 | 1 + b | bar | 1 | 1 b | | | 2 b | | 1 | 1 - b | | 2 | 1 - b | bar | 1 | 1 + b | bar | 2 | 1 b | bar | | 2 - | foo | | 2 - | foo | 1 | 1 + b | | 2 | 1 | | 2 | 3 + | | | 6 | bar | 1 | 2 | bar | 2 | 2 - | | | 6 - | foo | 2 | 1 | bar | | 4 + | foo | 1 | 1 + | foo | 2 | 1 + | foo | | 2 | | 1 | 3 (24 rows) @@ -360,29 +361,30 @@ SELECT dataa, datab b, generate_series(1,2) g, count(*) FROM few GROUP BY CUBE(d a | bar | 1 | 1 a | foo | 1 | 1 b | bar | 1 | 1 + | bar | 1 | 2 + | foo | 1 | 1 a | | 1 | 2 b | | 1 | 1 | | 1 | 3 - | bar | 1 | 2 - | foo | 1 | 1 - | foo | 2 | 1 - | bar | 2 | 2 a | | 2 | 2 b | | 2 | 1 - a | bar | 2 | 1 + | bar | 2 | 2 | | 2 | 3 + | foo | 2 | 1 + a | bar | 2 | 1 a | foo | 2 | 1 b | bar | 2 | 1 - a | foo | | 2 + a | | | 4 b | bar | | 2 b | | | 2 | | | 6 - a | | | 4 + a | foo | | 2 + a | bar | | 2 | bar | | 4 | foo | | 2 - a | bar | | 2 (24 rows) +reset enable_hashagg; -- data modification CREATE TABLE fewmore AS SELECT generate_series(1,3) AS data; INSERT INTO fewmore VALUES(generate_series(4,5)); diff --git a/src/test/regress/sql/groupingsets.sql b/src/test/regress/sql/groupingsets.sql index cc557cc552d..0e023d9ddc5 100644 --- a/src/test/regress/sql/groupingsets.sql +++ b/src/test/regress/sql/groupingsets.sql @@ -31,6 +31,14 @@ copy gstest3 from stdin; \. alter table gstest3 add primary key (a); +create temp table gstest4(id integer, v integer, + unhashable_col bit(4), unsortable_col xid); +insert into gstest4 +values (1,1,b'0000','1'), (2,2,b'0001','1'), + (3,4,b'0010','2'), (4,8,b'0011','2'), + (5,16,b'0000','2'), (6,32,b'0001','2'), + (7,64,b'0010','1'), (8,128,b'0011','1'); + create temp table gstest_empty (a integer, b integer, v integer); create function gstest_data(v integer, out a integer, out b integer) @@ -43,8 +51,11 @@ create function gstest_data(v integer, out a integer, out b integer) -- basic functionality +set enable_hashagg = false; -- test hashing explicitly later + -- simple rollup with multiple plain aggregates, with and without ordering -- (and with ordering differing from grouping) + select a, b, grouping(a,b), sum(v), count(*), max(v) from gstest1 group by rollup (a,b); select a, b, grouping(a,b), sum(v), count(*), max(v) @@ -161,7 +172,7 @@ select a, b from (values (1,2),(2,3)) v(a,b) group by a,b, grouping sets(a); -- Tests for chained aggregates select a, b, grouping(a,b), sum(v), count(*), max(v) - from gstest1 group by grouping sets ((a,b),(a+1,b+1),(a+2,b+2)); + from gstest1 group by grouping sets ((a,b),(a+1,b+1),(a+2,b+2)) order by 3,6; select(select (select grouping(a,b) from (values (1)) v2(c)) from (values (1,2)) v1(a,b) group by (a,b)) from (values(6,7)) v3(e,f) GROUP BY ROLLUP((e+1),(f+1)); select(select (select grouping(a,b) from (values (1)) v2(c)) from (values (1,2)) v1(a,b) group by (a,b)) from (values(6,7)) v3(e,f) GROUP BY CUBE((e+1),(f+1)) ORDER BY (e+1),(f+1); select a, b, sum(c), sum(sum(c)) over (order by a,b) as rsum @@ -224,4 +235,146 @@ select array(select row(v.a,s1.*) from (select two,four, count(*) from onek grou select sum(ten) from onek group by two, rollup(four::text) order by 1; select sum(ten) from onek group by rollup(four::text), two order by 1; +-- hashing support + +set enable_hashagg = true; + +-- failure cases + +select count(*) from gstest4 group by rollup(unhashable_col,unsortable_col); +select array_agg(v order by v) from gstest4 group by grouping sets ((id,unsortable_col),(id)); + +-- simple cases + +select a, b, grouping(a,b), sum(v), count(*), max(v) + from gstest1 group by grouping sets ((a),(b)) order by 3,1,2; +explain (costs off) select a, b, grouping(a,b), sum(v), count(*), max(v) + from gstest1 group by grouping sets ((a),(b)) order by 3,1,2; + +select a, b, grouping(a,b), sum(v), count(*), max(v) + from gstest1 group by cube(a,b) order by 3,1,2; +explain (costs off) select a, b, grouping(a,b), sum(v), count(*), max(v) + from gstest1 group by cube(a,b) order by 3,1,2; + +-- shouldn't try and hash +explain (costs off) + select a, b, grouping(a,b), array_agg(v order by v) + from gstest1 group by cube(a,b); + +-- mixed hashable/sortable cases +select unhashable_col, unsortable_col, + grouping(unhashable_col, unsortable_col), + count(*), sum(v) + from gstest4 group by grouping sets ((unhashable_col),(unsortable_col)) + order by 3, 5; +explain (costs off) + select unhashable_col, unsortable_col, + grouping(unhashable_col, unsortable_col), + count(*), sum(v) + from gstest4 group by grouping sets ((unhashable_col),(unsortable_col)) + order by 3,5; + +select unhashable_col, unsortable_col, + grouping(unhashable_col, unsortable_col), + count(*), sum(v) + from gstest4 group by grouping sets ((v,unhashable_col),(v,unsortable_col)) + order by 3,5; +explain (costs off) + select unhashable_col, unsortable_col, + grouping(unhashable_col, unsortable_col), + count(*), sum(v) + from gstest4 group by grouping sets ((v,unhashable_col),(v,unsortable_col)) + order by 3,5; + +-- 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); +explain (costs off) + 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),()); +select a, b, sum(v), count(*) from gstest_empty group by grouping sets ((a,b),(),(),()); +explain (costs off) + select a, b, sum(v), count(*) from gstest_empty group by grouping sets ((a,b),(),(),()); +select sum(v), count(*) from gstest_empty group by grouping sets ((),(),()); +explain (costs off) + select sum(v), count(*) from gstest_empty group by grouping sets ((),(),()); + +-- check that functionally dependent cols are not nulled +select a, d, grouping(a,b,c) + from gstest3 + group by grouping sets ((a,b), (a,c)); +explain (costs off) + select a, d, grouping(a,b,c) + from gstest3 + group by grouping sets ((a,b), (a,c)); + +-- simple rescan tests + +select a, b, sum(v.x) + from (values (1),(2)) v(x), gstest_data(v.x) + group by grouping sets (a,b); +explain (costs off) + select a, b, sum(v.x) + from (values (1),(2)) v(x), gstest_data(v.x) + group by grouping sets (a,b); + +select * + from (values (1),(2)) v(x), + lateral (select a, b, sum(v.x) from gstest_data(v.x) group by grouping sets (a,b)) s; +explain (costs off) + select * + from (values (1),(2)) v(x), + lateral (select a, b, sum(v.x) from gstest_data(v.x) group by grouping sets (a,b)) s; + +-- Tests for chained aggregates +select a, b, grouping(a,b), sum(v), count(*), max(v) + from gstest1 group by grouping sets ((a,b),(a+1,b+1),(a+2,b+2)) order by 3,6; +explain (costs off) + select a, b, grouping(a,b), sum(v), count(*), max(v) + from gstest1 group by grouping sets ((a,b),(a+1,b+1),(a+2,b+2)) order by 3,6; +select a, b, sum(c), sum(sum(c)) over (order by a,b) as rsum + from gstest2 group by cube (a,b) order by rsum, a, b; +explain (costs off) + select a, b, sum(c), sum(sum(c)) over (order by a,b) as rsum + from gstest2 group by cube (a,b) order by rsum, a, b; +select a, b, sum(v.x) + from (values (1),(2)) v(x), gstest_data(v.x) + group by cube (a,b) order by a,b; +explain (costs off) + select a, b, sum(v.x) + from (values (1),(2)) v(x), gstest_data(v.x) + group by cube (a,b) order by a,b; + +-- More rescan tests +select * from (values (1),(2)) v(a) left join lateral (select v.a, four, ten, count(*) from onek group by cube(four,ten)) s on true order by v.a,four,ten; +select array(select row(v.a,s1.*) from (select two,four, count(*) from onek group by cube(two,four) order by two,four) s1) from (values (1),(2)) v(a); + +-- Rescan logic changes when there are no empty grouping sets, so test +-- that too: +select * from (values (1),(2)) v(a) left join lateral (select v.a, four, ten, count(*) from onek group by grouping sets(four,ten)) s on true order by v.a,four,ten; +select array(select row(v.a,s1.*) from (select two,four, count(*) from onek group by grouping sets(two,four) order by two,four) s1) from (values (1),(2)) v(a); + +-- test the knapsack + +set work_mem = '64kB'; +explain (costs off) + select unique1, + count(two), count(four), count(ten), + count(hundred), count(thousand), count(twothousand), + count(*) + from tenk1 group by grouping sets (unique1,twothousand,thousand,hundred,ten,four,two); +explain (costs off) + select unique1, + count(two), count(four), count(ten), + count(hundred), count(thousand), count(twothousand), + count(*) + from tenk1 group by grouping sets (unique1,hundred,ten,four,two); + +set work_mem = '384kB'; +explain (costs off) + select unique1, + count(two), count(four), count(ten), + count(hundred), count(thousand), count(twothousand), + count(*) + from tenk1 group by grouping sets (unique1,twothousand,thousand,hundred,ten,four,two); + -- end diff --git a/src/test/regress/sql/tsrf.sql b/src/test/regress/sql/tsrf.sql index e627bb99ed9..417e78c53dd 100644 --- a/src/test/regress/sql/tsrf.sql +++ b/src/test/regress/sql/tsrf.sql @@ -66,12 +66,14 @@ SELECT SUM(count(*)) OVER(PARTITION BY generate_series(1,3) ORDER BY generate_se SELECT few.dataa, count(*), min(id), max(id), generate_series(1,3) FROM few GROUP BY few.dataa ORDER BY 5, 1; -- grouping sets are a bit special, they produce NULLs in columns not actually NULL +set enable_hashagg = false; SELECT dataa, datab b, generate_series(1,2) g, count(*) FROM few GROUP BY CUBE(dataa, datab); SELECT dataa, datab b, generate_series(1,2) g, count(*) FROM few GROUP BY CUBE(dataa, datab) ORDER BY dataa; SELECT dataa, datab b, generate_series(1,2) g, count(*) FROM few GROUP BY CUBE(dataa, datab) ORDER BY g; SELECT dataa, datab b, generate_series(1,2) g, count(*) FROM few GROUP BY CUBE(dataa, datab, g); SELECT dataa, datab b, generate_series(1,2) g, count(*) FROM few GROUP BY CUBE(dataa, datab, g) ORDER BY dataa; SELECT dataa, datab b, generate_series(1,2) g, count(*) FROM few GROUP BY CUBE(dataa, datab, g) ORDER BY g; +reset enable_hashagg; -- data modification CREATE TABLE fewmore AS SELECT generate_series(1,3) AS data; |
