Add more tests for hashing and hash-based plans

- Test hashing of an array of a non-hashable element type.

- Test UNION [DISTINCT] with hash- and sort-based plans.  (Previously,
  only INTERSECT and EXCEPT where tested there.)

- Test UNION [DISTINCT] with a non-hashable column type.  This
  currently reverts to a sort-based plan even if enable_hashagg is on.

- Test UNION/INTERSECT/EXCEPT hash- and sort-based plans with arrays
  as column types.  Also test an array with a non-hashable element
  type.

- Test UNION/INTERSECT/EXCEPT similarly with row types as column
  types.  Currently, this uses only sort-based plans because there is
  no hashing support for row types.

- Add a test case that shows that recursive queries using UNION
  [DISTINCT] require hashable column types.

- Add a currently failing test that uses UNION DISTINCT in a
  cycle-detection use case using row types as column types.

Discussion: https://www.postgresql.org/message-id/flat/38eccd35-4e2d-6767-1b3c-dada1eac3124%402ndquadrant.com
This commit is contained in:
Peter Eisentraut 2020-11-18 07:58:37 +01:00
parent bf0aa7c4b8
commit 6dd8b00807
6 changed files with 498 additions and 2 deletions

View File

@ -177,6 +177,13 @@ WHERE hash_array(v)::bit(32) != hash_array_extended(v, 0)::bit(32)
-------+----------+-----------+-----------
(0 rows)
-- array hashing with non-hashable element type
SELECT v as value, hash_array(v)::bit(32) as standard
FROM (VALUES ('{0}'::money[])) x(v);
ERROR: could not identify a hash function for type money
SELECT v as value, hash_array_extended(v, 0)::bit(32) as extended0
FROM (VALUES ('{0}'::money[])) x(v);
ERROR: could not identify an extended hash function for type money
SELECT v as value, hashbpchar(v)::bit(32) as standard,
hashbpcharextended(v, 0)::bit(32) as extended0,
hashbpcharextended(v, 1)::bit(32) as extended1

View File

@ -345,8 +345,28 @@ ERROR: FOR NO KEY UPDATE is not allowed with UNION/INTERSECT/EXCEPT
1 | 2 | 3
(1 row)
-- exercise both hashed and sorted implementations of INTERSECT/EXCEPT
-- exercise both hashed and sorted implementations of UNION/INTERSECT/EXCEPT
set enable_hashagg to on;
explain (costs off)
select count(*) from
( select unique1 from tenk1 union select fivethous from tenk1 ) ss;
QUERY PLAN
----------------------------------------------------------------
Aggregate
-> HashAggregate
Group Key: tenk1.unique1
-> Append
-> Index Only Scan using tenk1_unique1 on tenk1
-> Seq Scan on tenk1 tenk1_1
(6 rows)
select count(*) from
( select unique1 from tenk1 union select fivethous from tenk1 ) ss;
count
-------
10000
(1 row)
explain (costs off)
select count(*) from
( select unique1 from tenk1 intersect select fivethous from tenk1 ) ss;
@ -389,6 +409,27 @@ select unique1 from tenk1 except select unique2 from tenk1 where unique2 != 10;
(1 row)
set enable_hashagg to off;
explain (costs off)
select count(*) from
( select unique1 from tenk1 union select fivethous from tenk1 ) ss;
QUERY PLAN
----------------------------------------------------------------------
Aggregate
-> Unique
-> Sort
Sort Key: tenk1.unique1
-> Append
-> Index Only Scan using tenk1_unique1 on tenk1
-> Seq Scan on tenk1 tenk1_1
(7 rows)
select count(*) from
( select unique1 from tenk1 union select fivethous from tenk1 ) ss;
count
-------
10000
(1 row)
explain (costs off)
select count(*) from
( select unique1 from tenk1 intersect select fivethous from tenk1 ) ss;
@ -434,6 +475,320 @@ select unique1 from tenk1 except select unique2 from tenk1 where unique2 != 10;
10
(1 row)
reset enable_hashagg;
-- non-hashable type
set enable_hashagg to on;
explain (costs off)
select x from (values (100::money), (200::money)) _(x) union select x from (values (100::money), (300::money)) _(x);
QUERY PLAN
-----------------------------------------------
Unique
-> Sort
Sort Key: "*VALUES*".column1
-> Append
-> Values Scan on "*VALUES*"
-> Values Scan on "*VALUES*_1"
(6 rows)
set enable_hashagg to off;
explain (costs off)
select x from (values (100::money), (200::money)) _(x) union select x from (values (100::money), (300::money)) _(x);
QUERY PLAN
-----------------------------------------------
Unique
-> Sort
Sort Key: "*VALUES*".column1
-> Append
-> Values Scan on "*VALUES*"
-> Values Scan on "*VALUES*_1"
(6 rows)
reset enable_hashagg;
-- arrays
set enable_hashagg to on;
explain (costs off)
select x from (values (array[1, 2]), (array[1, 3])) _(x) union select x from (values (array[1, 2]), (array[1, 4])) _(x);
QUERY PLAN
-----------------------------------------
HashAggregate
Group Key: "*VALUES*".column1
-> Append
-> Values Scan on "*VALUES*"
-> Values Scan on "*VALUES*_1"
(5 rows)
select x from (values (array[1, 2]), (array[1, 3])) _(x) union select x from (values (array[1, 2]), (array[1, 4])) _(x);
x
-------
{1,4}
{1,2}
{1,3}
(3 rows)
explain (costs off)
select x from (values (array[1, 2]), (array[1, 3])) _(x) intersect select x from (values (array[1, 2]), (array[1, 4])) _(x);
QUERY PLAN
-----------------------------------------------
HashSetOp Intersect
-> Append
-> Subquery Scan on "*SELECT* 1"
-> Values Scan on "*VALUES*"
-> Subquery Scan on "*SELECT* 2"
-> Values Scan on "*VALUES*_1"
(6 rows)
select x from (values (array[1, 2]), (array[1, 3])) _(x) intersect select x from (values (array[1, 2]), (array[1, 4])) _(x);
x
-------
{1,2}
(1 row)
explain (costs off)
select x from (values (array[1, 2]), (array[1, 3])) _(x) except select x from (values (array[1, 2]), (array[1, 4])) _(x);
QUERY PLAN
-----------------------------------------------
HashSetOp Except
-> Append
-> Subquery Scan on "*SELECT* 1"
-> Values Scan on "*VALUES*"
-> Subquery Scan on "*SELECT* 2"
-> Values Scan on "*VALUES*_1"
(6 rows)
select x from (values (array[1, 2]), (array[1, 3])) _(x) except select x from (values (array[1, 2]), (array[1, 4])) _(x);
x
-------
{1,3}
(1 row)
-- non-hashable type
explain (costs off)
select x from (values (array[100::money]), (array[200::money])) _(x) union select x from (values (array[100::money]), (array[300::money])) _(x);
QUERY PLAN
-----------------------------------------------
Unique
-> Sort
Sort Key: "*VALUES*".column1
-> Append
-> Values Scan on "*VALUES*"
-> Values Scan on "*VALUES*_1"
(6 rows)
select x from (values (array[100::money]), (array[200::money])) _(x) union select x from (values (array[100::money]), (array[300::money])) _(x);
x
-----------
{$100.00}
{$200.00}
{$300.00}
(3 rows)
set enable_hashagg to off;
explain (costs off)
select x from (values (array[1, 2]), (array[1, 3])) _(x) union select x from (values (array[1, 2]), (array[1, 4])) _(x);
QUERY PLAN
-----------------------------------------------
Unique
-> Sort
Sort Key: "*VALUES*".column1
-> Append
-> Values Scan on "*VALUES*"
-> Values Scan on "*VALUES*_1"
(6 rows)
select x from (values (array[1, 2]), (array[1, 3])) _(x) union select x from (values (array[1, 2]), (array[1, 4])) _(x);
x
-------
{1,2}
{1,3}
{1,4}
(3 rows)
explain (costs off)
select x from (values (array[1, 2]), (array[1, 3])) _(x) intersect select x from (values (array[1, 2]), (array[1, 4])) _(x);
QUERY PLAN
-----------------------------------------------------
SetOp Intersect
-> Sort
Sort Key: "*SELECT* 1".x
-> Append
-> Subquery Scan on "*SELECT* 1"
-> Values Scan on "*VALUES*"
-> Subquery Scan on "*SELECT* 2"
-> Values Scan on "*VALUES*_1"
(8 rows)
select x from (values (array[1, 2]), (array[1, 3])) _(x) intersect select x from (values (array[1, 2]), (array[1, 4])) _(x);
x
-------
{1,2}
(1 row)
explain (costs off)
select x from (values (array[1, 2]), (array[1, 3])) _(x) except select x from (values (array[1, 2]), (array[1, 4])) _(x);
QUERY PLAN
-----------------------------------------------------
SetOp Except
-> Sort
Sort Key: "*SELECT* 1".x
-> Append
-> Subquery Scan on "*SELECT* 1"
-> Values Scan on "*VALUES*"
-> Subquery Scan on "*SELECT* 2"
-> Values Scan on "*VALUES*_1"
(8 rows)
select x from (values (array[1, 2]), (array[1, 3])) _(x) except select x from (values (array[1, 2]), (array[1, 4])) _(x);
x
-------
{1,3}
(1 row)
reset enable_hashagg;
-- records
set enable_hashagg to on;
-- currently no hashing support for record, so these will still run with sort plans:
explain (costs off)
select x from (values (row(1, 2)), (row(1, 3))) _(x) union select x from (values (row(1, 2)), (row(1, 4))) _(x);
QUERY PLAN
-----------------------------------------------
Unique
-> Sort
Sort Key: "*VALUES*".column1
-> Append
-> Values Scan on "*VALUES*"
-> Values Scan on "*VALUES*_1"
(6 rows)
select x from (values (row(1, 2)), (row(1, 3))) _(x) union select x from (values (row(1, 2)), (row(1, 4))) _(x);
x
-------
(1,2)
(1,3)
(1,4)
(3 rows)
explain (costs off)
select x from (values (row(1, 2)), (row(1, 3))) _(x) intersect select x from (values (row(1, 2)), (row(1, 4))) _(x);
QUERY PLAN
-----------------------------------------------------
SetOp Intersect
-> Sort
Sort Key: "*SELECT* 1".x
-> Append
-> Subquery Scan on "*SELECT* 1"
-> Values Scan on "*VALUES*"
-> Subquery Scan on "*SELECT* 2"
-> Values Scan on "*VALUES*_1"
(8 rows)
select x from (values (row(1, 2)), (row(1, 3))) _(x) intersect select x from (values (row(1, 2)), (row(1, 4))) _(x);
x
-------
(1,2)
(1 row)
explain (costs off)
select x from (values (row(1, 2)), (row(1, 3))) _(x) except select x from (values (row(1, 2)), (row(1, 4))) _(x);
QUERY PLAN
-----------------------------------------------------
SetOp Except
-> Sort
Sort Key: "*SELECT* 1".x
-> Append
-> Subquery Scan on "*SELECT* 1"
-> Values Scan on "*VALUES*"
-> Subquery Scan on "*SELECT* 2"
-> Values Scan on "*VALUES*_1"
(8 rows)
select x from (values (row(1, 2)), (row(1, 3))) _(x) except select x from (values (row(1, 2)), (row(1, 4))) _(x);
x
-------
(1,3)
(1 row)
-- non-hashable type
explain (costs off)
select x from (values (row(100::money)), (row(200::money))) _(x) union select x from (values (row(100::money)), (row(300::money))) _(x);
QUERY PLAN
-----------------------------------------------
Unique
-> Sort
Sort Key: "*VALUES*".column1
-> Append
-> Values Scan on "*VALUES*"
-> Values Scan on "*VALUES*_1"
(6 rows)
select x from (values (row(100::money)), (row(200::money))) _(x) union select x from (values (row(100::money)), (row(300::money))) _(x);
x
-----------
($100.00)
($200.00)
($300.00)
(3 rows)
set enable_hashagg to off;
explain (costs off)
select x from (values (row(1, 2)), (row(1, 3))) _(x) union select x from (values (row(1, 2)), (row(1, 4))) _(x);
QUERY PLAN
-----------------------------------------------
Unique
-> Sort
Sort Key: "*VALUES*".column1
-> Append
-> Values Scan on "*VALUES*"
-> Values Scan on "*VALUES*_1"
(6 rows)
select x from (values (row(1, 2)), (row(1, 3))) _(x) union select x from (values (row(1, 2)), (row(1, 4))) _(x);
x
-------
(1,2)
(1,3)
(1,4)
(3 rows)
explain (costs off)
select x from (values (row(1, 2)), (row(1, 3))) _(x) intersect select x from (values (row(1, 2)), (row(1, 4))) _(x);
QUERY PLAN
-----------------------------------------------------
SetOp Intersect
-> Sort
Sort Key: "*SELECT* 1".x
-> Append
-> Subquery Scan on "*SELECT* 1"
-> Values Scan on "*VALUES*"
-> Subquery Scan on "*SELECT* 2"
-> Values Scan on "*VALUES*_1"
(8 rows)
select x from (values (row(1, 2)), (row(1, 3))) _(x) intersect select x from (values (row(1, 2)), (row(1, 4))) _(x);
x
-------
(1,2)
(1 row)
explain (costs off)
select x from (values (row(1, 2)), (row(1, 3))) _(x) except select x from (values (row(1, 2)), (row(1, 4))) _(x);
QUERY PLAN
-----------------------------------------------------
SetOp Except
-> Sort
Sort Key: "*SELECT* 1".x
-> Append
-> Subquery Scan on "*SELECT* 1"
-> Values Scan on "*VALUES*"
-> Subquery Scan on "*SELECT* 2"
-> Values Scan on "*VALUES*_1"
(8 rows)
select x from (values (row(1, 2)), (row(1, 3))) _(x) except select x from (values (row(1, 2)), (row(1, 4))) _(x);
x
-------
(1,3)
(1 row)
reset enable_hashagg;
--
-- Mixed types

View File

@ -49,6 +49,15 @@ SELECT * FROM t;
5
(5 rows)
-- UNION DISTINCT requires hashable type
WITH RECURSIVE t(n) AS (
VALUES (1::money)
UNION
SELECT n+1::money FROM t WHERE n < 100::money
)
SELECT sum(n) FROM t;
ERROR: could not implement recursive UNION
DETAIL: All column datatypes must be hashable.
-- recursive view
CREATE RECURSIVE VIEW nums (n) AS
VALUES (1)
@ -616,6 +625,17 @@ select * from search_graph;
2 | 3 | arc 2 -> 3 | f | {"(1,4)","(4,5)","(5,1)","(1,2)","(2,3)"}
(25 rows)
-- UNION DISTINCT currently not supported here because row types not hashable
with recursive search_graph(f, t, label, is_cycle, path) as (
select *, false, array[row(g.f, g.t)] from graph g
union distinct
select g.*, row(g.f, g.t) = any(path), path || row(g.f, g.t)
from graph g, search_graph sg
where g.f = sg.t and not is_cycle
)
select * from search_graph;
ERROR: could not implement recursive UNION
DETAIL: All column datatypes must be hashable.
-- ordering by the path column has same effect as SEARCH DEPTH FIRST
with recursive search_graph(f, t, label, is_cycle, path) as (
select *, false, array[row(g.f, g.t)] from graph g

View File

@ -130,6 +130,12 @@ FROM (VALUES ('{0}'::int4[]), ('{0,1,2,3,4}'), ('{17,18,19,20}'),
WHERE hash_array(v)::bit(32) != hash_array_extended(v, 0)::bit(32)
OR hash_array(v)::bit(32) = hash_array_extended(v, 1)::bit(32);
-- array hashing with non-hashable element type
SELECT v as value, hash_array(v)::bit(32) as standard
FROM (VALUES ('{0}'::money[])) x(v);
SELECT v as value, hash_array_extended(v, 0)::bit(32) as extended0
FROM (VALUES ('{0}'::money[])) x(v);
SELECT v as value, hashbpchar(v)::bit(32) as standard,
hashbpcharextended(v, 0)::bit(32) as extended0,
hashbpcharextended(v, 1)::bit(32) as extended1

View File

@ -118,10 +118,16 @@ SELECT q1 FROM int8_tbl EXCEPT ALL SELECT q1 FROM int8_tbl FOR NO KEY UPDATE;
(SELECT 1,2,3 UNION SELECT 4,5,6) EXCEPT SELECT 4,5,6;
(SELECT 1,2,3 UNION SELECT 4,5,6 ORDER BY 1,2) EXCEPT SELECT 4,5,6;
-- exercise both hashed and sorted implementations of INTERSECT/EXCEPT
-- exercise both hashed and sorted implementations of UNION/INTERSECT/EXCEPT
set enable_hashagg to on;
explain (costs off)
select count(*) from
( select unique1 from tenk1 union select fivethous from tenk1 ) ss;
select count(*) from
( select unique1 from tenk1 union select fivethous from tenk1 ) ss;
explain (costs off)
select count(*) from
( select unique1 from tenk1 intersect select fivethous from tenk1 ) ss;
@ -134,6 +140,12 @@ select unique1 from tenk1 except select unique2 from tenk1 where unique2 != 10;
set enable_hashagg to off;
explain (costs off)
select count(*) from
( select unique1 from tenk1 union select fivethous from tenk1 ) ss;
select count(*) from
( select unique1 from tenk1 union select fivethous from tenk1 ) ss;
explain (costs off)
select count(*) from
( select unique1 from tenk1 intersect select fivethous from tenk1 ) ss;
@ -146,6 +158,84 @@ select unique1 from tenk1 except select unique2 from tenk1 where unique2 != 10;
reset enable_hashagg;
-- non-hashable type
set enable_hashagg to on;
explain (costs off)
select x from (values (100::money), (200::money)) _(x) union select x from (values (100::money), (300::money)) _(x);
set enable_hashagg to off;
explain (costs off)
select x from (values (100::money), (200::money)) _(x) union select x from (values (100::money), (300::money)) _(x);
reset enable_hashagg;
-- arrays
set enable_hashagg to on;
explain (costs off)
select x from (values (array[1, 2]), (array[1, 3])) _(x) union select x from (values (array[1, 2]), (array[1, 4])) _(x);
select x from (values (array[1, 2]), (array[1, 3])) _(x) union select x from (values (array[1, 2]), (array[1, 4])) _(x);
explain (costs off)
select x from (values (array[1, 2]), (array[1, 3])) _(x) intersect select x from (values (array[1, 2]), (array[1, 4])) _(x);
select x from (values (array[1, 2]), (array[1, 3])) _(x) intersect select x from (values (array[1, 2]), (array[1, 4])) _(x);
explain (costs off)
select x from (values (array[1, 2]), (array[1, 3])) _(x) except select x from (values (array[1, 2]), (array[1, 4])) _(x);
select x from (values (array[1, 2]), (array[1, 3])) _(x) except select x from (values (array[1, 2]), (array[1, 4])) _(x);
-- non-hashable type
explain (costs off)
select x from (values (array[100::money]), (array[200::money])) _(x) union select x from (values (array[100::money]), (array[300::money])) _(x);
select x from (values (array[100::money]), (array[200::money])) _(x) union select x from (values (array[100::money]), (array[300::money])) _(x);
set enable_hashagg to off;
explain (costs off)
select x from (values (array[1, 2]), (array[1, 3])) _(x) union select x from (values (array[1, 2]), (array[1, 4])) _(x);
select x from (values (array[1, 2]), (array[1, 3])) _(x) union select x from (values (array[1, 2]), (array[1, 4])) _(x);
explain (costs off)
select x from (values (array[1, 2]), (array[1, 3])) _(x) intersect select x from (values (array[1, 2]), (array[1, 4])) _(x);
select x from (values (array[1, 2]), (array[1, 3])) _(x) intersect select x from (values (array[1, 2]), (array[1, 4])) _(x);
explain (costs off)
select x from (values (array[1, 2]), (array[1, 3])) _(x) except select x from (values (array[1, 2]), (array[1, 4])) _(x);
select x from (values (array[1, 2]), (array[1, 3])) _(x) except select x from (values (array[1, 2]), (array[1, 4])) _(x);
reset enable_hashagg;
-- records
set enable_hashagg to on;
-- currently no hashing support for record, so these will still run with sort plans:
explain (costs off)
select x from (values (row(1, 2)), (row(1, 3))) _(x) union select x from (values (row(1, 2)), (row(1, 4))) _(x);
select x from (values (row(1, 2)), (row(1, 3))) _(x) union select x from (values (row(1, 2)), (row(1, 4))) _(x);
explain (costs off)
select x from (values (row(1, 2)), (row(1, 3))) _(x) intersect select x from (values (row(1, 2)), (row(1, 4))) _(x);
select x from (values (row(1, 2)), (row(1, 3))) _(x) intersect select x from (values (row(1, 2)), (row(1, 4))) _(x);
explain (costs off)
select x from (values (row(1, 2)), (row(1, 3))) _(x) except select x from (values (row(1, 2)), (row(1, 4))) _(x);
select x from (values (row(1, 2)), (row(1, 3))) _(x) except select x from (values (row(1, 2)), (row(1, 4))) _(x);
-- non-hashable type
explain (costs off)
select x from (values (row(100::money)), (row(200::money))) _(x) union select x from (values (row(100::money)), (row(300::money))) _(x);
select x from (values (row(100::money)), (row(200::money))) _(x) union select x from (values (row(100::money)), (row(300::money))) _(x);
set enable_hashagg to off;
explain (costs off)
select x from (values (row(1, 2)), (row(1, 3))) _(x) union select x from (values (row(1, 2)), (row(1, 4))) _(x);
select x from (values (row(1, 2)), (row(1, 3))) _(x) union select x from (values (row(1, 2)), (row(1, 4))) _(x);
explain (costs off)
select x from (values (row(1, 2)), (row(1, 3))) _(x) intersect select x from (values (row(1, 2)), (row(1, 4))) _(x);
select x from (values (row(1, 2)), (row(1, 3))) _(x) intersect select x from (values (row(1, 2)), (row(1, 4))) _(x);
explain (costs off)
select x from (values (row(1, 2)), (row(1, 3))) _(x) except select x from (values (row(1, 2)), (row(1, 4))) _(x);
select x from (values (row(1, 2)), (row(1, 3))) _(x) except select x from (values (row(1, 2)), (row(1, 4))) _(x);
reset enable_hashagg;
--
-- Mixed types
--

View File

@ -31,6 +31,14 @@ UNION ALL
)
SELECT * FROM t;
-- UNION DISTINCT requires hashable type
WITH RECURSIVE t(n) AS (
VALUES (1::money)
UNION
SELECT n+1::money FROM t WHERE n < 100::money
)
SELECT sum(n) FROM t;
-- recursive view
CREATE RECURSIVE VIEW nums (n) AS
VALUES (1)
@ -317,6 +325,16 @@ with recursive search_graph(f, t, label, is_cycle, path) as (
)
select * from search_graph;
-- UNION DISTINCT currently not supported here because row types not hashable
with recursive search_graph(f, t, label, is_cycle, path) as (
select *, false, array[row(g.f, g.t)] from graph g
union distinct
select g.*, row(g.f, g.t) = any(path), path || row(g.f, g.t)
from graph g, search_graph sg
where g.f = sg.t and not is_cycle
)
select * from search_graph;
-- ordering by the path column has same effect as SEARCH DEPTH FIRST
with recursive search_graph(f, t, label, is_cycle, path) as (
select *, false, array[row(g.f, g.t)] from graph g