From 05ea20d7e234a0a12773d8db04ebb76c987fa95e Mon Sep 17 00:00:00 2001 From: Jason Kim Date: Wed, 21 Jun 2023 18:12:40 -0700 Subject: [PATCH] [#17869] YSQL: fix incorrect optimization on NULL scans Summary: There is an optimization to avoid performing a scan when the condition is unsatisfiable. The logic for determining whether a condition is unsatisfiable has flaws: - It has an inverted condition: rather than looking for a row filter whose first key is null, it looks for a row filter where any key but the first is null. - It reads data out-of-bounds from an array: it tries to read keys[-1]. Fix both issues. To test, add a debug log when an unsatisfiable condition is found. Also add a psql variable YB_DISABLE_ERROR_PREFIX to avoid adding a prefix to client messages when a file is being read because that prefix includes a line number which can easily change over the course of edits to the file. Add test cases to exercise the unsatisfiable conditions. Also add DIST to the EXPLAINs for further assurance that RPCs are not sent. Jira: DB-6953 Test Plan: Expect the following to fail on only the yb_index_scan test due to issue #17750. ./yb_build.sh fastdebug --gcc11 --java-test TestPgRegressIndex Close: #17869 Reviewers: tnayak Reviewed By: tnayak Subscribers: kramanathan, yql Differential Revision: https://phorge.dev.yugabyte.com/D26352 --- .../src/backend/access/yb_access/yb_scan.c | 26 ++-- src/postgres/src/bin/psql/common.c | 2 +- .../expected/yb_index_scan_null_asc.out | 145 ++++++++++++++---- .../expected/yb_index_scan_null_create.out | 8 +- .../expected/yb_index_scan_null_hash.out | 119 +++++++++++--- .../regress/sql/yb_index_scan_null_create.sql | 8 +- .../sql/yb_index_scan_null_queries.sql | 48 ++++-- 7 files changed, 280 insertions(+), 76 deletions(-) diff --git a/src/postgres/src/backend/access/yb_access/yb_scan.c b/src/postgres/src/backend/access/yb_access/yb_scan.c index 23cf399fd68a..281aa5ec6706 100644 --- a/src/postgres/src/backend/access/yb_access/yb_scan.c +++ b/src/postgres/src/backend/access/yb_access/yb_scan.c @@ -757,22 +757,28 @@ YbGetLengthOfKey(ScanKey *key_ptr) } /* - * Check whether the conditions lead to empty result regardless of the values - * in the index because of always FALSE or UNKNOWN conditions. - * Return true if the combined key conditions are unsatisfiable. + * Return whether the given conditions are unsatisfiable regardless of the + * values in the index because of always FALSE or UNKNOWN conditions. */ static bool -YbIsEmptyResultCondition(int nkeys, ScanKey keys[]) +YbIsUnsatisfiableCondition(int nkeys, ScanKey keys[]) { - for (int i = 0; i < nkeys; i++) + for (int i = 0; i < nkeys; ++i) { ScanKey key = keys[i]; - if (!((key->sk_flags & SK_ROW_MEMBER) && YbIsRowHeader(keys[i - 1])) || - key->sk_strategy == BTEqualStrategyNumber) + /* + * Look for two cases: + * - = null + * - row(a, b, c) op row(null, e, f) + */ + if ((key->sk_strategy == BTEqualStrategyNumber || + (i > 0 && YbIsRowHeader(keys[i - 1]) && + key->sk_flags & SK_ROW_MEMBER)) && + YbIsNeverTrueNullCond(key)) { - if (YbIsNeverTrueNullCond(key)) - return true; + elog(DEBUG1, "skipping a scan due to unsatisfiable condition"); + return true; } } return false; @@ -2083,7 +2089,7 @@ ybcBeginScan(Relation relation, ybcSetupScanPlan(xs_want_itup, ybScan, &scan_plan); ybcSetupScanKeys(ybScan, &scan_plan); - if (!YbIsEmptyResultCondition(ybScan->nkeys, ybScan->keys) && + if (!YbIsUnsatisfiableCondition(ybScan->nkeys, ybScan->keys) && YbBindScanKeys(ybScan, &scan_plan) && YbBindHashKeys(ybScan)) { diff --git a/src/postgres/src/bin/psql/common.c b/src/postgres/src/bin/psql/common.c index 8c5feee90077..cf21f84b25b8 100644 --- a/src/postgres/src/bin/psql/common.c +++ b/src/postgres/src/bin/psql/common.c @@ -228,7 +228,7 @@ psql_error(const char *fmt,...) if (pset.queryFout && pset.queryFout != stdout) fflush(pset.queryFout); - if (pset.inputfile) + if (pset.inputfile && !GetVariable(pset.vars, "YB_DISABLE_ERROR_PREFIX")) fprintf(stderr, "%s:%s:" UINT64_FORMAT ": ", pset.progname, pset.inputfile, pset.lineno); va_start(ap, fmt); vfprintf(stderr, _(fmt), ap); diff --git a/src/postgres/src/test/regress/expected/yb_index_scan_null_asc.out b/src/postgres/src/test/regress/expected/yb_index_scan_null_asc.out index 57e00160a50d..f9a1d22f4529 100644 --- a/src/postgres/src/test/regress/expected/yb_index_scan_null_asc.out +++ b/src/postgres/src/test/regress/expected/yb_index_scan_null_asc.out @@ -8,134 +8,213 @@ DROP INDEX IF EXISTS i_nulltest_ba; CREATE INDEX i_nulltest_ba ON nulltest (b ASC, a ASC); \i sql/yb_index_scan_null_queries.sql -- Queries for the null scan key tests +SET client_min_messages = DEBUG1; +\set YB_DISABLE_ERROR_PREFIX on -- Should return empty results (actual rows=0) -- The plans should not show any "Recheck" -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) NestLoop(t2 t1) Leading((t2 t1)) */ SELECT * FROM nulltest t1 JOIN nulltest2 t2 ON t1.a = t2.x; - QUERY PLAN +DEBUG: skipping a scan due to unsatisfiable condition + QUERY PLAN ---------------------------------------------------------------------------- Nested Loop (actual rows=0 loops=1) -> Seq Scan on nulltest2 t2 (actual rows=1 loops=1) + Storage Table Read Requests: 3 -> Index Scan using i_nulltest_a on nulltest t1 (actual rows=0 loops=1) Index Cond: (a = t2.x) -(4 rows) +(5 rows) -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) NestLoop(t2 t1) Leading((t2 t1)) */ SELECT * FROM nulltest t1 JOIN nulltest2 t2 ON t1.a <= t2.x; - QUERY PLAN + QUERY PLAN ---------------------------------------------------------------------------- Nested Loop (actual rows=0 loops=1) -> Seq Scan on nulltest2 t2 (actual rows=1 loops=1) + Storage Table Read Requests: 3 -> Index Scan using i_nulltest_a on nulltest t1 (actual rows=0 loops=1) Index Cond: (a <= t2.x) -(4 rows) + Storage Index Read Requests: 1 +(6 rows) -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) NestLoop(t2 t1) Leading((t2 t1)) */ SELECT * FROM nulltest t1 JOIN nulltest2 t2 ON t1.a BETWEEN t2.x AND t2.x + 2; - QUERY PLAN + QUERY PLAN ---------------------------------------------------------------------------- Nested Loop (actual rows=0 loops=1) -> Seq Scan on nulltest2 t2 (actual rows=1 loops=1) + Storage Table Read Requests: 3 -> Index Scan using i_nulltest_a on nulltest t1 (actual rows=0 loops=1) Index Cond: ((a >= t2.x) AND (a <= (t2.x + 2))) -(4 rows) + Storage Index Read Requests: 1 +(6 rows) -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) NestLoop(t2 t1) Leading((t2 t1)) */ SELECT * FROM nulltest t1 JOIN nulltest2 t2 ON (t1.a, t1.b) = (t2.x, t2.y); - QUERY PLAN +DEBUG: skipping a scan due to unsatisfiable condition + QUERY PLAN ----------------------------------------------------------------------------- Nested Loop (actual rows=0 loops=1) -> Seq Scan on nulltest2 t2 (actual rows=1 loops=1) + Storage Table Read Requests: 3 -> Index Scan using i_nulltest_ba on nulltest t1 (actual rows=0 loops=1) Index Cond: ((b = t2.y) AND (a = t2.x)) -(4 rows) +(5 rows) -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) NestLoop(t2 t1) Leading((t2 t1)) */ SELECT * FROM nulltest t1 JOIN nulltest2 t2 ON (t1.a, t1.b) <= (t2.x, t2.y); - QUERY PLAN + QUERY PLAN ---------------------------------------------------------------------------- Nested Loop (actual rows=0 loops=1) -> Seq Scan on nulltest2 t2 (actual rows=1 loops=1) + Storage Table Read Requests: 3 -> Index Scan using i_nulltest_a on nulltest t1 (actual rows=0 loops=1) Index Cond: (a <= t2.x) Filter: (ROW(a, b) <= ROW(t2.x, t2.y)) -(5 rows) + Storage Index Read Requests: 1 +(7 rows) -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) */ SELECT * FROM nulltest t1 WHERE (a, b) <= (null, 1); - QUERY PLAN + QUERY PLAN ---------------------------------------------------------------------- Index Scan using i_nulltest_a on nulltest t1 (actual rows=0 loops=1) Index Cond: (a <= NULL::integer) Filter: (ROW(a, b) <= ROW(NULL::integer, 1)) -(3 rows) + Storage Index Read Requests: 1 +(4 rows) + +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) +/*+ IndexScan(t1 i_nulltest_ba) */ +SELECT * FROM nulltest t1 WHERE (a, b) <= (null, 1); +DEBUG: skipping a scan due to unsatisfiable condition + QUERY PLAN +----------------------------------------------------------------------- + Index Scan using i_nulltest_ba on nulltest t1 (actual rows=0 loops=1) + Index Cond: (ROW(a, b) <= ROW(NULL::integer, 1)) +(2 rows) -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) */ SELECT a FROM nulltest t1 WHERE a IN (null, null); - QUERY PLAN + QUERY PLAN ---------------------------------------------------------------------- Index Scan using i_nulltest_a on nulltest t1 (actual rows=0 loops=1) Index Cond: (a = ANY ('{NULL,NULL}'::integer[])) (2 rows) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) +/*+ IndexScan(t1 i_nulltest_ba) */ +SELECT a FROM nulltest t1 WHERE a IN (null, null); + QUERY PLAN +----------------------------------------------------------------------- + Index Scan using i_nulltest_ba on nulltest t1 (actual rows=0 loops=1) + Index Cond: (a = ANY ('{NULL,NULL}'::integer[])) +(2 rows) + -- Should return 1s /*+ IndexScan(t1) */ SELECT a FROM nulltest t1 WHERE a IN (null, 1); - a + a --- 1 1 (2 rows) -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) */ SELECT a FROM nulltest t1 WHERE a IN (null, 1); - QUERY PLAN + QUERY PLAN ---------------------------------------------------------------------- Index Scan using i_nulltest_a on nulltest t1 (actual rows=2 loops=1) Index Cond: (a = ANY ('{NULL,1}'::integer[])) + Storage Table Read Requests: 1 + Storage Index Read Requests: 1 +(4 rows) + +/*+ IndexScan(t1 i_nulltest_ba) */ +SELECT a FROM nulltest t1 WHERE a IN (null, 1); + a +--- + 1 + 1 (2 rows) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) +/*+ IndexScan(t1 i_nulltest_ba) */ +SELECT a FROM nulltest t1 WHERE a IN (null, 1); + QUERY PLAN +----------------------------------------------------------------------- + Index Scan using i_nulltest_ba on nulltest t1 (actual rows=2 loops=1) + Index Cond: (a = ANY ('{NULL,1}'::integer[])) + Storage Table Read Requests: 1 + Storage Index Read Requests: 1 +(4 rows) + /*+ IndexScan(t1) */ SELECT a FROM nulltest t1 WHERE (a, b) <= (2, null); - a + a --- 1 1 (2 rows) -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) */ SELECT a FROM nulltest t1 WHERE (a, b) <= (2, null); - QUERY PLAN + QUERY PLAN ---------------------------------------------------------------------- Index Scan using i_nulltest_a on nulltest t1 (actual rows=2 loops=1) Index Cond: (a <= 2) Filter: (ROW(a, b) <= ROW(2, NULL::integer)) -(3 rows) + Storage Table Read Requests: 1 + Storage Index Read Requests: 1 +(5 rows) + +/*+ IndexScan(t1 i_nulltest_ba) */ +SELECT a FROM nulltest t1 WHERE (a, b) <= (2, null); + a +--- + 1 + 1 +(2 rows) + +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) +/*+ IndexScan(t1 i_nulltest_ba) */ +SELECT a FROM nulltest t1 WHERE (a, b) <= (2, null); + QUERY PLAN +----------------------------------------------------------------------- + Index Scan using i_nulltest_ba on nulltest t1 (actual rows=2 loops=1) + Index Cond: (ROW(a, b) <= ROW(2, NULL::integer)) + Rows Removed by Index Recheck: 2 + Storage Table Read Requests: 1 + Storage Index Read Requests: 1 +(5 rows) -- Should return nulls /*+ IndexScan(t1) */ SELECT a FROM nulltest t1 WHERE a IS NULL; - a + a --- - - + + (2 rows) -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) */ SELECT a FROM nulltest t1 WHERE a IS NULL; - QUERY PLAN + QUERY PLAN ---------------------------------------------------------------------- Index Scan using i_nulltest_a on nulltest t1 (actual rows=2 loops=1) Index Cond: (a IS NULL) -(2 rows) + Storage Table Read Requests: 1 + Storage Index Read Requests: 1 +(4 rows) +RESET client_min_messages; +\unset YB_DISABLE_ERROR_PREFIX diff --git a/src/postgres/src/test/regress/expected/yb_index_scan_null_create.out b/src/postgres/src/test/regress/expected/yb_index_scan_null_create.out index bbb1ba9159fe..c54bd983b6d6 100644 --- a/src/postgres/src/test/regress/expected/yb_index_scan_null_create.out +++ b/src/postgres/src/test/regress/expected/yb_index_scan_null_create.out @@ -1,5 +1,9 @@ -- Create tables for the null scan key tests -CREATE TABLE nulltest (a int, b int); +-- +-- As of 2023-06-21, the tables will default to 3 tablets, but in case those +-- defaults change, explicitly set the numbers here. The number of tablets +-- affects the number of requests shown in EXPLAIN DIST. +CREATE TABLE nulltest (a int, b int) SPLIT INTO 3 TABLETS; INSERT INTO nulltest VALUES (null, null), (null, 1), (1, null), (1, 1); -CREATE TABLE nulltest2 (x int, y int); +CREATE TABLE nulltest2 (x int, y int) SPLIT INTO 3 TABLETS; INSERT INTO nulltest2 VALUES (null, null); diff --git a/src/postgres/src/test/regress/expected/yb_index_scan_null_hash.out b/src/postgres/src/test/regress/expected/yb_index_scan_null_hash.out index c28074e2b992..3e20718fcdba 100644 --- a/src/postgres/src/test/regress/expected/yb_index_scan_null_hash.out +++ b/src/postgres/src/test/regress/expected/yb_index_scan_null_hash.out @@ -8,20 +8,24 @@ DROP INDEX IF EXISTS i_nulltest_ba; CREATE INDEX i_nulltest_ba ON nulltest ((b, a) HASH); \i sql/yb_index_scan_null_queries.sql -- Queries for the null scan key tests +SET client_min_messages = DEBUG1; +\set YB_DISABLE_ERROR_PREFIX on -- Should return empty results (actual rows=0) -- The plans should not show any "Recheck" -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) NestLoop(t2 t1) Leading((t2 t1)) */ SELECT * FROM nulltest t1 JOIN nulltest2 t2 ON t1.a = t2.x; +DEBUG: skipping a scan due to unsatisfiable condition QUERY PLAN ---------------------------------------------------------------------------- Nested Loop (actual rows=0 loops=1) -> Seq Scan on nulltest2 t2 (actual rows=1 loops=1) + Storage Table Read Requests: 3 -> Index Scan using i_nulltest_a on nulltest t1 (actual rows=0 loops=1) Index Cond: (a = t2.x) -(4 rows) +(5 rows) -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) NestLoop(t2 t1) Leading((t2 t1)) */ SELECT * FROM nulltest t1 JOIN nulltest2 t2 ON t1.a <= t2.x; QUERY PLAN @@ -30,11 +34,13 @@ SELECT * FROM nulltest t1 JOIN nulltest2 t2 ON t1.a <= t2.x; Join Filter: (t1.a <= t2.x) Rows Removed by Join Filter: 4 -> Seq Scan on nulltest2 t2 (actual rows=1 loops=1) + Storage Table Read Requests: 3 -> Materialize (actual rows=4 loops=1) -> YB Seq Scan on nulltest t1 (actual rows=4 loops=1) -(6 rows) + Storage Table Read Requests: 3 +(8 rows) -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) NestLoop(t2 t1) Leading((t2 t1)) */ SELECT * FROM nulltest t1 JOIN nulltest2 t2 ON t1.a BETWEEN t2.x AND t2.x + 2; QUERY PLAN @@ -43,22 +49,26 @@ SELECT * FROM nulltest t1 JOIN nulltest2 t2 ON t1.a BETWEEN t2.x AND t2.x + 2; Join Filter: ((t1.a >= t2.x) AND (t1.a <= (t2.x + 2))) Rows Removed by Join Filter: 4 -> Seq Scan on nulltest2 t2 (actual rows=1 loops=1) + Storage Table Read Requests: 3 -> Materialize (actual rows=4 loops=1) -> YB Seq Scan on nulltest t1 (actual rows=4 loops=1) -(6 rows) + Storage Table Read Requests: 3 +(8 rows) -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) NestLoop(t2 t1) Leading((t2 t1)) */ SELECT * FROM nulltest t1 JOIN nulltest2 t2 ON (t1.a, t1.b) = (t2.x, t2.y); +DEBUG: skipping a scan due to unsatisfiable condition QUERY PLAN ----------------------------------------------------------------------------- Nested Loop (actual rows=0 loops=1) -> Seq Scan on nulltest2 t2 (actual rows=1 loops=1) + Storage Table Read Requests: 3 -> Index Scan using i_nulltest_ba on nulltest t1 (actual rows=0 loops=1) Index Cond: ((b = t2.y) AND (a = t2.x)) -(4 rows) +(5 rows) -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) NestLoop(t2 t1) Leading((t2 t1)) */ SELECT * FROM nulltest t1 JOIN nulltest2 t2 ON (t1.a, t1.b) <= (t2.x, t2.y); QUERY PLAN @@ -67,11 +77,13 @@ SELECT * FROM nulltest t1 JOIN nulltest2 t2 ON (t1.a, t1.b) <= (t2.x, t2.y); Join Filter: (ROW(t1.a, t1.b) <= ROW(t2.x, t2.y)) Rows Removed by Join Filter: 4 -> Seq Scan on nulltest2 t2 (actual rows=1 loops=1) + Storage Table Read Requests: 3 -> Materialize (actual rows=4 loops=1) -> YB Seq Scan on nulltest t1 (actual rows=4 loops=1) -(6 rows) + Storage Table Read Requests: 3 +(8 rows) -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) */ SELECT * FROM nulltest t1 WHERE (a, b) <= (null, 1); QUERY PLAN @@ -79,9 +91,21 @@ SELECT * FROM nulltest t1 WHERE (a, b) <= (null, 1); YB Seq Scan on nulltest t1 (actual rows=0 loops=1) Filter: (ROW(a, b) <= ROW(NULL::integer, 1)) Rows Removed by Filter: 4 -(3 rows) + Storage Table Read Requests: 3 +(4 rows) + +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) +/*+ IndexScan(t1 i_nulltest_ba) */ +SELECT * FROM nulltest t1 WHERE (a, b) <= (null, 1); + QUERY PLAN +---------------------------------------------------- + YB Seq Scan on nulltest t1 (actual rows=0 loops=1) + Filter: (ROW(a, b) <= ROW(NULL::integer, 1)) + Rows Removed by Filter: 4 + Storage Table Read Requests: 3 +(4 rows) -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) */ SELECT a FROM nulltest t1 WHERE a IN (null, null); QUERY PLAN @@ -90,6 +114,18 @@ SELECT a FROM nulltest t1 WHERE a IN (null, null); Index Cond: (a = ANY ('{NULL,NULL}'::integer[])) (2 rows) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) +/*+ IndexScan(t1 i_nulltest_ba) */ +SELECT a FROM nulltest t1 WHERE a IN (null, null); + QUERY PLAN +----------------------------------------------------------------------- + Index Scan using i_nulltest_ba on nulltest t1 (actual rows=0 loops=1) + Index Cond: (a = ANY ('{NULL,NULL}'::integer[])) + Rows Removed by Index Recheck: 4 + Storage Table Read Requests: 2 + Storage Index Read Requests: 3 +(5 rows) + -- Should return 1s /*+ IndexScan(t1) */ SELECT a FROM nulltest t1 WHERE a IN (null, 1); @@ -99,15 +135,37 @@ SELECT a FROM nulltest t1 WHERE a IN (null, 1); 1 (2 rows) -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) */ SELECT a FROM nulltest t1 WHERE a IN (null, 1); QUERY PLAN ---------------------------------------------------------------------- Index Scan using i_nulltest_a on nulltest t1 (actual rows=2 loops=1) Index Cond: (a = ANY ('{NULL,1}'::integer[])) + Storage Table Read Requests: 1 + Storage Index Read Requests: 1 +(4 rows) + +/*+ IndexScan(t1 i_nulltest_ba) */ +SELECT a FROM nulltest t1 WHERE a IN (null, 1); + a +--- + 1 + 1 (2 rows) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) +/*+ IndexScan(t1 i_nulltest_ba) */ +SELECT a FROM nulltest t1 WHERE a IN (null, 1); + QUERY PLAN +----------------------------------------------------------------------- + Index Scan using i_nulltest_ba on nulltest t1 (actual rows=2 loops=1) + Index Cond: (a = ANY ('{NULL,1}'::integer[])) + Rows Removed by Index Recheck: 2 + Storage Table Read Requests: 2 + Storage Index Read Requests: 3 +(5 rows) + /*+ IndexScan(t1) */ SELECT a FROM nulltest t1 WHERE (a, b) <= (2, null); a @@ -116,7 +174,7 @@ SELECT a FROM nulltest t1 WHERE (a, b) <= (2, null); 1 (2 rows) -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) */ SELECT a FROM nulltest t1 WHERE (a, b) <= (2, null); QUERY PLAN @@ -124,7 +182,27 @@ SELECT a FROM nulltest t1 WHERE (a, b) <= (2, null); YB Seq Scan on nulltest t1 (actual rows=2 loops=1) Filter: (ROW(a, b) <= ROW(2, NULL::integer)) Rows Removed by Filter: 2 -(3 rows) + Storage Table Read Requests: 3 +(4 rows) + +/*+ IndexScan(t1 i_nulltest_ba) */ +SELECT a FROM nulltest t1 WHERE (a, b) <= (2, null); + a +--- + 1 + 1 +(2 rows) + +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) +/*+ IndexScan(t1 i_nulltest_ba) */ +SELECT a FROM nulltest t1 WHERE (a, b) <= (2, null); + QUERY PLAN +---------------------------------------------------- + YB Seq Scan on nulltest t1 (actual rows=2 loops=1) + Filter: (ROW(a, b) <= ROW(2, NULL::integer)) + Rows Removed by Filter: 2 + Storage Table Read Requests: 3 +(4 rows) -- Should return nulls /*+ IndexScan(t1) */ @@ -135,11 +213,16 @@ SELECT a FROM nulltest t1 WHERE a IS NULL; (2 rows) -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) */ SELECT a FROM nulltest t1 WHERE a IS NULL; QUERY PLAN ---------------------------------------------------------------------- Index Scan using i_nulltest_a on nulltest t1 (actual rows=2 loops=1) Index Cond: (a IS NULL) -(2 rows) + Storage Table Read Requests: 1 + Storage Index Read Requests: 1 +(4 rows) + +RESET client_min_messages; +\unset YB_DISABLE_ERROR_PREFIX diff --git a/src/postgres/src/test/regress/sql/yb_index_scan_null_create.sql b/src/postgres/src/test/regress/sql/yb_index_scan_null_create.sql index d6f88c798425..29ffe7329276 100644 --- a/src/postgres/src/test/regress/sql/yb_index_scan_null_create.sql +++ b/src/postgres/src/test/regress/sql/yb_index_scan_null_create.sql @@ -1,7 +1,11 @@ -- Create tables for the null scan key tests +-- +-- As of 2023-06-21, the tables will default to 3 tablets, but in case those +-- defaults change, explicitly set the numbers here. The number of tablets +-- affects the number of requests shown in EXPLAIN DIST. -CREATE TABLE nulltest (a int, b int); +CREATE TABLE nulltest (a int, b int) SPLIT INTO 3 TABLETS; INSERT INTO nulltest VALUES (null, null), (null, 1), (1, null), (1, 1); -CREATE TABLE nulltest2 (x int, y int); +CREATE TABLE nulltest2 (x int, y int) SPLIT INTO 3 TABLETS; INSERT INTO nulltest2 VALUES (null, null); diff --git a/src/postgres/src/test/regress/sql/yb_index_scan_null_queries.sql b/src/postgres/src/test/regress/sql/yb_index_scan_null_queries.sql index cf0e4ae19494..0b4fce5879cc 100644 --- a/src/postgres/src/test/regress/sql/yb_index_scan_null_queries.sql +++ b/src/postgres/src/test/regress/sql/yb_index_scan_null_queries.sql @@ -1,56 +1,84 @@ -- Queries for the null scan key tests +SET client_min_messages = DEBUG1; +\set YB_DISABLE_ERROR_PREFIX on + -- Should return empty results (actual rows=0) -- The plans should not show any "Recheck" -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) NestLoop(t2 t1) Leading((t2 t1)) */ SELECT * FROM nulltest t1 JOIN nulltest2 t2 ON t1.a = t2.x; -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) NestLoop(t2 t1) Leading((t2 t1)) */ SELECT * FROM nulltest t1 JOIN nulltest2 t2 ON t1.a <= t2.x; -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) NestLoop(t2 t1) Leading((t2 t1)) */ SELECT * FROM nulltest t1 JOIN nulltest2 t2 ON t1.a BETWEEN t2.x AND t2.x + 2; -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) NestLoop(t2 t1) Leading((t2 t1)) */ SELECT * FROM nulltest t1 JOIN nulltest2 t2 ON (t1.a, t1.b) = (t2.x, t2.y); -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) NestLoop(t2 t1) Leading((t2 t1)) */ SELECT * FROM nulltest t1 JOIN nulltest2 t2 ON (t1.a, t1.b) <= (t2.x, t2.y); -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) */ SELECT * FROM nulltest t1 WHERE (a, b) <= (null, 1); -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) +/*+ IndexScan(t1 i_nulltest_ba) */ +SELECT * FROM nulltest t1 WHERE (a, b) <= (null, 1); + +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) */ SELECT a FROM nulltest t1 WHERE a IN (null, null); +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) +/*+ IndexScan(t1 i_nulltest_ba) */ +SELECT a FROM nulltest t1 WHERE a IN (null, null); + -- Should return 1s /*+ IndexScan(t1) */ SELECT a FROM nulltest t1 WHERE a IN (null, 1); -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) */ SELECT a FROM nulltest t1 WHERE a IN (null, 1); +/*+ IndexScan(t1 i_nulltest_ba) */ +SELECT a FROM nulltest t1 WHERE a IN (null, 1); + +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) +/*+ IndexScan(t1 i_nulltest_ba) */ +SELECT a FROM nulltest t1 WHERE a IN (null, 1); + /*+ IndexScan(t1) */ SELECT a FROM nulltest t1 WHERE (a, b) <= (2, null); -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) */ SELECT a FROM nulltest t1 WHERE (a, b) <= (2, null); +/*+ IndexScan(t1 i_nulltest_ba) */ +SELECT a FROM nulltest t1 WHERE (a, b) <= (2, null); + +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) +/*+ IndexScan(t1 i_nulltest_ba) */ +SELECT a FROM nulltest t1 WHERE (a, b) <= (2, null); + -- Should return nulls /*+ IndexScan(t1) */ SELECT a FROM nulltest t1 WHERE a IS NULL; -EXPLAIN (ANALYZE, COSTS OFF, TIMING OFF, SUMMARY OFF) +EXPLAIN (ANALYZE, COSTS OFF, DIST ON, TIMING OFF, SUMMARY OFF) /*+ IndexScan(t1) */ SELECT a FROM nulltest t1 WHERE a IS NULL; + +RESET client_min_messages; +\unset YB_DISABLE_ERROR_PREFIX