From 1633123d78576f6cc3c88df65e83273a3b884dbb Mon Sep 17 00:00:00 2001 From: Marco Slot Date: Fri, 13 Dec 2019 08:35:54 +0100 Subject: [PATCH] Fix crash in IN (NULL) queries --- .../distributed/planner/shard_pruning.c | 9 ++++ .../regress/expected/multi_router_planner.out | 47 ++++++++++++------- src/test/regress/sql/multi_router_planner.sql | 5 +- 3 files changed, 42 insertions(+), 19 deletions(-) diff --git a/src/backend/distributed/planner/shard_pruning.c b/src/backend/distributed/planner/shard_pruning.c index 2ebb9a70d..1e4e48d55 100644 --- a/src/backend/distributed/planner/shard_pruning.c +++ b/src/backend/distributed/planner/shard_pruning.c @@ -668,6 +668,15 @@ AddSAOPartitionKeyRestrictionToInstance(ClauseWalkerContext *context, ArrayIterator arrayIterator = array_create_iterator(array, 0, NULL); while (array_iterate(arrayIterator, &arrayElement, &isNull)) { + if (isNull) + { + /* + * We can ignore IN (NULL) clauses because a value is never + * equal to NULL. + */ + continue; + } + Const *constElement = makeConst(elementType, -1, DEFAULT_COLLATION_OID, typlen, arrayElement, isNull, typbyval); diff --git a/src/test/regress/expected/multi_router_planner.out b/src/test/regress/expected/multi_router_planner.out index 3addc6299..871ef8a68 100644 --- a/src/test/regress/expected/multi_router_planner.out +++ b/src/test/regress/expected/multi_router_planner.out @@ -255,7 +255,7 @@ DETAIL: distribution column value: 1 -- query is a single shard query but can't do shard pruning, -- not router-plannable due to <= and IN -SELECT * FROM articles_hash WHERE author_id <= 1; +SELECT * FROM articles_hash WHERE author_id <= 1 ORDER BY id; DEBUG: Router planner cannot handle multi-shard select queries id | author_id | title | word_count ----+-----------+--------------+------------ @@ -266,7 +266,7 @@ DEBUG: Router planner cannot handle multi-shard select queries 41 | 1 | aznavour | 11814 (5 rows) -SELECT * FROM articles_hash WHERE author_id IN (1, 3); +SELECT * FROM articles_hash WHERE author_id IN (1, 3) ORDER BY id; DEBUG: Creating router plan DEBUG: Plan is router executable id | author_id | title | word_count @@ -283,6 +283,19 @@ DEBUG: Plan is router executable 43 | 3 | affixal | 12723 (10 rows) +SELECT * FROM articles_hash WHERE author_id IN (1, NULL) ORDER BY id; +DEBUG: Creating router plan +DEBUG: Plan is router executable +DETAIL: distribution column value: 1 + id | author_id | title | word_count +----+-----------+--------------+------------ + 1 | 1 | arsenous | 9572 + 11 | 1 | alamo | 1347 + 21 | 1 | arcading | 5890 + 31 | 1 | athwartships | 7271 + 41 | 1 | aznavour | 11814 +(5 rows) + -- queries with CTEs are supported WITH first_author AS ( SELECT id FROM articles_hash WHERE author_id = 1) SELECT * FROM first_author; @@ -343,15 +356,15 @@ WITH id_author AS ( SELECT id, author_id FROM articles_hash WHERE author_id = 1) id_title AS (SELECT id, title from articles_hash WHERE author_id = 2) SELECT * FROM id_author, id_title WHERE id_author.id = id_title.id; DEBUG: cannot run command which targets multiple shards -DEBUG: generating subplan 67_1 for CTE id_author: SELECT id, author_id FROM public.articles_hash WHERE (author_id OPERATOR(pg_catalog.=) 1) +DEBUG: generating subplan 68_1 for CTE id_author: SELECT id, author_id FROM public.articles_hash WHERE (author_id OPERATOR(pg_catalog.=) 1) DEBUG: Creating router plan DEBUG: Plan is router executable DETAIL: distribution column value: 1 -DEBUG: generating subplan 67_2 for CTE id_title: SELECT id, title FROM public.articles_hash WHERE (author_id OPERATOR(pg_catalog.=) 2) +DEBUG: generating subplan 68_2 for CTE id_title: SELECT id, title FROM public.articles_hash WHERE (author_id OPERATOR(pg_catalog.=) 2) DEBUG: Creating router plan DEBUG: Plan is router executable DETAIL: distribution column value: 2 -DEBUG: Plan 67 query after replacing subqueries and CTEs: SELECT id_author.id, id_author.author_id, id_title.id, id_title.title FROM (SELECT intermediate_result.id, intermediate_result.author_id FROM read_intermediate_result('67_1'::text, 'binary'::citus_copy_format) intermediate_result(id bigint, author_id bigint)) id_author, (SELECT intermediate_result.id, intermediate_result.title FROM read_intermediate_result('67_2'::text, 'binary'::citus_copy_format) intermediate_result(id bigint, title character varying(20))) id_title WHERE (id_author.id OPERATOR(pg_catalog.=) id_title.id) +DEBUG: Plan 68 query after replacing subqueries and CTEs: SELECT id_author.id, id_author.author_id, id_title.id, id_title.title FROM (SELECT intermediate_result.id, intermediate_result.author_id FROM read_intermediate_result('68_1'::text, 'binary'::citus_copy_format) intermediate_result(id bigint, author_id bigint)) id_author, (SELECT intermediate_result.id, intermediate_result.title FROM read_intermediate_result('68_2'::text, 'binary'::citus_copy_format) intermediate_result(id bigint, title character varying(20))) id_title WHERE (id_author.id OPERATOR(pg_catalog.=) id_title.id) DEBUG: Creating router plan DEBUG: Plan is router executable id | author_id | id | title @@ -461,11 +474,11 @@ WITH new_article AS ( ) SELECT * FROM new_article; DEBUG: data-modifying statements are not supported in the WITH clauses of distributed queries -DEBUG: generating subplan 81_1 for CTE new_article: INSERT INTO public.articles_hash (id, author_id, title, word_count) VALUES (1, 1, 'arsenous'::character varying, 9) RETURNING id, author_id, title, word_count +DEBUG: generating subplan 82_1 for CTE new_article: INSERT INTO public.articles_hash (id, author_id, title, word_count) VALUES (1, 1, 'arsenous'::character varying, 9) RETURNING id, author_id, title, word_count DEBUG: Creating router plan DEBUG: Plan is router executable DETAIL: distribution column value: 1 -DEBUG: Plan 81 query after replacing subqueries and CTEs: SELECT id, author_id, title, word_count FROM (SELECT intermediate_result.id, intermediate_result.author_id, intermediate_result.title, intermediate_result.word_count FROM read_intermediate_result('81_1'::text, 'binary'::citus_copy_format) intermediate_result(id bigint, author_id bigint, title character varying(20), word_count integer)) new_article +DEBUG: Plan 82 query after replacing subqueries and CTEs: SELECT id, author_id, title, word_count FROM (SELECT intermediate_result.id, intermediate_result.author_id, intermediate_result.title, intermediate_result.word_count FROM read_intermediate_result('82_1'::text, 'binary'::citus_copy_format) intermediate_result(id bigint, author_id bigint, title character varying(20), word_count integer)) new_article DEBUG: Creating router plan DEBUG: Plan is router executable id | author_id | title | word_count @@ -478,10 +491,10 @@ WITH update_article AS ( ) SELECT * FROM update_article; DEBUG: data-modifying statements are not supported in the WITH clauses of distributed queries -DEBUG: generating subplan 83_1 for CTE update_article: UPDATE public.articles_hash SET word_count = 10 WHERE ((id OPERATOR(pg_catalog.=) 1) AND (word_count OPERATOR(pg_catalog.=) 9)) RETURNING id, author_id, title, word_count +DEBUG: generating subplan 84_1 for CTE update_article: UPDATE public.articles_hash SET word_count = 10 WHERE ((id OPERATOR(pg_catalog.=) 1) AND (word_count OPERATOR(pg_catalog.=) 9)) RETURNING id, author_id, title, word_count DEBUG: Creating router plan DEBUG: Plan is router executable -DEBUG: Plan 83 query after replacing subqueries and CTEs: SELECT id, author_id, title, word_count FROM (SELECT intermediate_result.id, intermediate_result.author_id, intermediate_result.title, intermediate_result.word_count FROM read_intermediate_result('83_1'::text, 'binary'::citus_copy_format) intermediate_result(id bigint, author_id bigint, title character varying(20), word_count integer)) update_article +DEBUG: Plan 84 query after replacing subqueries and CTEs: SELECT id, author_id, title, word_count FROM (SELECT intermediate_result.id, intermediate_result.author_id, intermediate_result.title, intermediate_result.word_count FROM read_intermediate_result('84_1'::text, 'binary'::citus_copy_format) intermediate_result(id bigint, author_id bigint, title character varying(20), word_count integer)) update_article DEBUG: Creating router plan DEBUG: Plan is router executable id | author_id | title | word_count @@ -494,10 +507,10 @@ WITH delete_article AS ( ) SELECT * FROM delete_article; DEBUG: data-modifying statements are not supported in the WITH clauses of distributed queries -DEBUG: generating subplan 85_1 for CTE delete_article: DELETE FROM public.articles_hash WHERE ((id OPERATOR(pg_catalog.=) 1) AND (word_count OPERATOR(pg_catalog.=) 10)) RETURNING id, author_id, title, word_count +DEBUG: generating subplan 86_1 for CTE delete_article: DELETE FROM public.articles_hash WHERE ((id OPERATOR(pg_catalog.=) 1) AND (word_count OPERATOR(pg_catalog.=) 10)) RETURNING id, author_id, title, word_count DEBUG: Creating router plan DEBUG: Plan is router executable -DEBUG: Plan 85 query after replacing subqueries and CTEs: SELECT id, author_id, title, word_count FROM (SELECT intermediate_result.id, intermediate_result.author_id, intermediate_result.title, intermediate_result.word_count FROM read_intermediate_result('85_1'::text, 'binary'::citus_copy_format) intermediate_result(id bigint, author_id bigint, title character varying(20), word_count integer)) delete_article +DEBUG: Plan 86 query after replacing subqueries and CTEs: SELECT id, author_id, title, word_count FROM (SELECT intermediate_result.id, intermediate_result.author_id, intermediate_result.title, intermediate_result.word_count FROM read_intermediate_result('86_1'::text, 'binary'::citus_copy_format) intermediate_result(id bigint, author_id bigint, title character varying(20), word_count integer)) delete_article DEBUG: Creating router plan DEBUG: Plan is router executable id | author_id | title | word_count @@ -633,8 +646,8 @@ FROM articles_hash, (SELECT id, word_count FROM articles_hash) AS test WHERE tes ORDER BY test.word_count DESC, articles_hash.id LIMIT 5; DEBUG: Router planner cannot handle multi-shard select queries DEBUG: Router planner cannot handle multi-shard select queries -DEBUG: generating subplan 93_1 for subquery SELECT id, word_count FROM public.articles_hash -DEBUG: Plan 93 query after replacing subqueries and CTEs: SELECT articles_hash.id, test.word_count FROM public.articles_hash, (SELECT intermediate_result.id, intermediate_result.word_count FROM read_intermediate_result('93_1'::text, 'binary'::citus_copy_format) intermediate_result(id bigint, word_count integer)) test WHERE (test.id OPERATOR(pg_catalog.=) articles_hash.id) ORDER BY test.word_count DESC, articles_hash.id LIMIT 5 +DEBUG: generating subplan 94_1 for subquery SELECT id, word_count FROM public.articles_hash +DEBUG: Plan 94 query after replacing subqueries and CTEs: SELECT articles_hash.id, test.word_count FROM public.articles_hash, (SELECT intermediate_result.id, intermediate_result.word_count FROM read_intermediate_result('94_1'::text, 'binary'::citus_copy_format) intermediate_result(id bigint, word_count integer)) test WHERE (test.id OPERATOR(pg_catalog.=) articles_hash.id) ORDER BY test.word_count DESC, articles_hash.id LIMIT 5 DEBUG: Router planner cannot handle multi-shard select queries DEBUG: push down of limit count: 5 id | word_count @@ -652,8 +665,8 @@ WHERE test.id = articles_hash.id and articles_hash.author_id = 1 ORDER BY articles_hash.id; DEBUG: Router planner cannot handle multi-shard select queries DEBUG: Router planner cannot handle multi-shard select queries -DEBUG: generating subplan 95_1 for subquery SELECT id, word_count FROM public.articles_hash -DEBUG: Plan 95 query after replacing subqueries and CTEs: SELECT articles_hash.id, test.word_count FROM public.articles_hash, (SELECT intermediate_result.id, intermediate_result.word_count FROM read_intermediate_result('95_1'::text, 'binary'::citus_copy_format) intermediate_result(id bigint, word_count integer)) test WHERE ((test.id OPERATOR(pg_catalog.=) articles_hash.id) AND (articles_hash.author_id OPERATOR(pg_catalog.=) 1)) ORDER BY articles_hash.id +DEBUG: generating subplan 96_1 for subquery SELECT id, word_count FROM public.articles_hash +DEBUG: Plan 96 query after replacing subqueries and CTEs: SELECT articles_hash.id, test.word_count FROM public.articles_hash, (SELECT intermediate_result.id, intermediate_result.word_count FROM read_intermediate_result('96_1'::text, 'binary'::citus_copy_format) intermediate_result(id bigint, word_count integer)) test WHERE ((test.id OPERATOR(pg_catalog.=) articles_hash.id) AND (articles_hash.author_id OPERATOR(pg_catalog.=) 1)) ORDER BY articles_hash.id DEBUG: Creating router plan DEBUG: Plan is router executable DETAIL: distribution column value: 1 @@ -777,10 +790,10 @@ SELECT a.author_id as first_author, b.word_count as second_word_count LIMIT 3; DEBUG: Found no worker with all shard placements DEBUG: found no worker with all shard placements -DEBUG: generating subplan 104_1 for CTE single_shard: SELECT id, author_id, title, word_count FROM public.articles_single_shard_hash +DEBUG: generating subplan 105_1 for CTE single_shard: SELECT id, author_id, title, word_count FROM public.articles_single_shard_hash DEBUG: Creating router plan DEBUG: Plan is router executable -DEBUG: Plan 104 query after replacing subqueries and CTEs: SELECT a.author_id AS first_author, b.word_count AS second_word_count FROM public.articles_hash a, (SELECT intermediate_result.id, intermediate_result.author_id, intermediate_result.title, intermediate_result.word_count FROM read_intermediate_result('104_1'::text, 'binary'::citus_copy_format) intermediate_result(id bigint, author_id bigint, title character varying(20), word_count integer)) b WHERE ((a.author_id OPERATOR(pg_catalog.=) 2) AND (a.author_id OPERATOR(pg_catalog.=) b.author_id)) LIMIT 3 +DEBUG: Plan 105 query after replacing subqueries and CTEs: SELECT a.author_id AS first_author, b.word_count AS second_word_count FROM public.articles_hash a, (SELECT intermediate_result.id, intermediate_result.author_id, intermediate_result.title, intermediate_result.word_count FROM read_intermediate_result('105_1'::text, 'binary'::citus_copy_format) intermediate_result(id bigint, author_id bigint, title character varying(20), word_count integer)) b WHERE ((a.author_id OPERATOR(pg_catalog.=) 2) AND (a.author_id OPERATOR(pg_catalog.=) b.author_id)) LIMIT 3 DEBUG: Creating router plan DEBUG: Plan is router executable DETAIL: distribution column value: 2 diff --git a/src/test/regress/sql/multi_router_planner.sql b/src/test/regress/sql/multi_router_planner.sql index bd9f2c8dc..5bbcdebb3 100644 --- a/src/test/regress/sql/multi_router_planner.sql +++ b/src/test/regress/sql/multi_router_planner.sql @@ -159,8 +159,9 @@ SELECT author_id, sum(word_count) AS corpus_size FROM articles_hash -- query is a single shard query but can't do shard pruning, -- not router-plannable due to <= and IN -SELECT * FROM articles_hash WHERE author_id <= 1; -SELECT * FROM articles_hash WHERE author_id IN (1, 3); +SELECT * FROM articles_hash WHERE author_id <= 1 ORDER BY id; +SELECT * FROM articles_hash WHERE author_id IN (1, 3) ORDER BY id; +SELECT * FROM articles_hash WHERE author_id IN (1, NULL) ORDER BY id; -- queries with CTEs are supported WITH first_author AS ( SELECT id FROM articles_hash WHERE author_id = 1)