From e92d75fbf6f359ad1895a938efb6fa42b886697b Mon Sep 17 00:00:00 2001 From: Michael Paquier Date: Tue, 20 Aug 2024 12:20:39 +0900 Subject: [PATCH] Add Parallel hint tests for empty tables. As a result of the discussion with Sami Imseih, this commit adds tests showing that for empty tables, only parallel index scans can be enforced and not sequential scans. This is an old, historical, rather weird behavior, that may not be worth changing in the long run as empry tables are not something users rely a lot when using pg_hint_plan, but let's add a test tracking if any future change impacts the plans generated. Author: Sami Imseih Backpatch-through: 17 Per discussion on issue #164. --- expected/ut-W.out | 74 ++++++++++++++++++++++++++++++++++++++++++++ expected/ut-init.out | 4 +++ sql/ut-W.sql | 16 ++++++++++ sql/ut-init.sql | 4 +++ 4 files changed, 98 insertions(+) diff --git a/expected/ut-W.out b/expected/ut-W.out index 1d11380..ce2a055 100644 --- a/expected/ut-W.out +++ b/expected/ut-W.out @@ -1121,6 +1121,80 @@ error hint: -> Parallel Seq Scan on p2_c3_c2 p2_8 (21 rows) +-- On empty tables, parallel hints can only be enforced for index scans +-- and not sequential scans. Adding a single row allows a parallel +-- hint to be enforced on a sequential scan. It is a bit weird that +-- having no rows controls how parallel workers are triggered, but +-- at the same time we have nothing to query, and this is an old +-- historical (and accidental) behavior. +/*+Parallel(t5 4 hard) Parallel(t6 2 hard)*/ +EXPLAIN (COSTS false) SELECT * FROM s1.t5 NATURAL JOIN s1.t6; +LOG: pg_hint_plan: +used hint: +Parallel(t5 4 hard) +Parallel(t6 2 hard) +not used hint: +duplication hint: +error hint: + + QUERY PLAN +---------------------------------------------------------------------------------------------- + Nested Loop + Join Filter: ((t5.c1 = t6.c1) AND (t6.c2 = t5.c2) AND (t6.c3 = t5.c3) AND (t6.c4 = t5.c4)) + -> Seq Scan on t5 + -> Seq Scan on t6 +(4 rows) + +/*+Parallel(t5 4 hard) Parallel(t6 2 hard) NoSeqScan(t5) NoSeqScan(t6) */ +EXPLAIN (COSTS false) SELECT * FROM s1.t5 NATURAL JOIN s1.t6; +LOG: pg_hint_plan: +used hint: +NoSeqScan(t5) +NoSeqScan(t6) +Parallel(t5 4 hard) +Parallel(t6 2 hard) +not used hint: +duplication hint: +error hint: + + QUERY PLAN +---------------------------------------------------------------------------------------------- + Nested Loop + Join Filter: ((t5.c1 = t6.c1) AND (t6.c2 = t5.c2) AND (t6.c3 = t5.c3) AND (t6.c4 = t5.c4)) + -> Gather + Workers Planned: 4 + -> Parallel Index Scan using t5_pkey on t5 + -> Gather + Workers Planned: 2 + -> Parallel Index Scan using t6_pkey on t6 +(8 rows) + +INSERT INTO s1.t5 SELECT i, i, i % 10, i FROM (SELECT generate_series(1, 1) i) t; +INSERT INTO s1.t6 SELECT i, i, i % 10, i FROM (SELECT generate_series(1, 1) i) t; +ANALYZE s1.t5; +ANALYZE s1.t6; +/*+Parallel(t5 4 hard) Parallel(t6 2 hard)*/ +EXPLAIN (COSTS false) SELECT * FROM s1.t5 NATURAL JOIN s1.t6; +LOG: pg_hint_plan: +used hint: +Parallel(t5 4 hard) +Parallel(t6 2 hard) +not used hint: +duplication hint: +error hint: + + QUERY PLAN +---------------------------------------------------------------------------------------------- + Nested Loop + Join Filter: ((t5.c1 = t6.c1) AND (t6.c2 = t5.c2) AND (t6.c3 = t5.c3) AND (t6.c4 = t5.c4)) + -> Gather + Workers Planned: 4 + -> Parallel Seq Scan on t5 + -> Gather + Workers Planned: 2 + -> Parallel Seq Scan on t6 +(8 rows) + -- Negative hints SET enable_indexscan to DEFAULT; SET parallel_setup_cost to 0; diff --git a/expected/ut-init.out b/expected/ut-init.out index c8fc34d..9172ac9 100644 --- a/expected/ut-init.out +++ b/expected/ut-init.out @@ -23,6 +23,8 @@ CREATE TABLE s1.t1 (c1 int, c2 int, c3 int, c4 text, PRIMARY KEY (c1)); CREATE TABLE s1.t2 (LIKE s1.t1 INCLUDING ALL); CREATE TABLE s1.t3 (LIKE s1.t1 INCLUDING ALL); CREATE TABLE s1.t4 (LIKE s1.t1 INCLUDING ALL); +CREATE TABLE s1.t5 (LIKE s1.t1 INCLUDING ALL); +CREATE TABLE s1.t6 (LIKE s1.t1 INCLUDING ALL); CREATE TABLE s2.t1 (LIKE s1.t1 INCLUDING ALL); CREATE TABLE s1.p1 (LIKE s1.t1 INCLUDING ALL); CREATE UNIQUE INDEX p1_parent ON s1.p1 USING btree (c4 COLLATE "C" varchar_ops ASC NULLS LAST, (c1 * 2 < 100)) WHERE c1 < 10; @@ -180,6 +182,8 @@ ANALYZE s1.p2c3c1; ANALYZE s1.p2c3c2; ANALYZE s1.ti1; ANALYZE s1.pt1; +ANALYZE s1.t5; +ANALYZE s1.t6; CREATE FUNCTION s1.f1 () RETURNS s1.t1 AS $$ VALUES(1,1,1,'1'), (2,2,2,'2'), (3,3,3,'3') $$ LANGUAGE sql; diff --git a/sql/ut-W.sql b/sql/ut-W.sql index 091ed00..ed30377 100644 --- a/sql/ut-W.sql +++ b/sql/ut-W.sql @@ -183,6 +183,22 @@ SET max_parallel_workers_per_gather to 8; /*+Parallel(p1 5 hard)Parallel(p2 6 hard) */ EXPLAIN (COSTS false) SELECT id FROM p1 UNION ALL SELECT id FROM p2; +-- On empty tables, parallel hints can only be enforced for index scans +-- and not sequential scans. Adding a single row allows a parallel +-- hint to be enforced on a sequential scan. It is a bit weird that +-- having no rows controls how parallel workers are triggered, but +-- at the same time we have nothing to query, and this is an old +-- historical (and accidental) behavior. +/*+Parallel(t5 4 hard) Parallel(t6 2 hard)*/ +EXPLAIN (COSTS false) SELECT * FROM s1.t5 NATURAL JOIN s1.t6; +/*+Parallel(t5 4 hard) Parallel(t6 2 hard) NoSeqScan(t5) NoSeqScan(t6) */ +EXPLAIN (COSTS false) SELECT * FROM s1.t5 NATURAL JOIN s1.t6; +INSERT INTO s1.t5 SELECT i, i, i % 10, i FROM (SELECT generate_series(1, 1) i) t; +INSERT INTO s1.t6 SELECT i, i, i % 10, i FROM (SELECT generate_series(1, 1) i) t; +ANALYZE s1.t5; +ANALYZE s1.t6; +/*+Parallel(t5 4 hard) Parallel(t6 2 hard)*/ +EXPLAIN (COSTS false) SELECT * FROM s1.t5 NATURAL JOIN s1.t6; -- Negative hints SET enable_indexscan to DEFAULT; diff --git a/sql/ut-init.sql b/sql/ut-init.sql index c0d961a..c148e7c 100644 --- a/sql/ut-init.sql +++ b/sql/ut-init.sql @@ -27,6 +27,8 @@ CREATE TABLE s1.t1 (c1 int, c2 int, c3 int, c4 text, PRIMARY KEY (c1)); CREATE TABLE s1.t2 (LIKE s1.t1 INCLUDING ALL); CREATE TABLE s1.t3 (LIKE s1.t1 INCLUDING ALL); CREATE TABLE s1.t4 (LIKE s1.t1 INCLUDING ALL); +CREATE TABLE s1.t5 (LIKE s1.t1 INCLUDING ALL); +CREATE TABLE s1.t6 (LIKE s1.t1 INCLUDING ALL); CREATE TABLE s2.t1 (LIKE s1.t1 INCLUDING ALL); CREATE TABLE s1.p1 (LIKE s1.t1 INCLUDING ALL); CREATE UNIQUE INDEX p1_parent ON s1.p1 USING btree (c4 COLLATE "C" varchar_ops ASC NULLS LAST, (c1 * 2 < 100)) WHERE c1 < 10; @@ -135,6 +137,8 @@ ANALYZE s1.p2c3c1; ANALYZE s1.p2c3c2; ANALYZE s1.ti1; ANALYZE s1.pt1; +ANALYZE s1.t5; +ANALYZE s1.t6; CREATE FUNCTION s1.f1 () RETURNS s1.t1 AS $$ VALUES(1,1,1,'1'), (2,2,2,'2'), (3,3,3,'3')