Skip to content

Commit

Permalink
Fix #7787
Browse files Browse the repository at this point in the history
  • Loading branch information
colm-mchugh committed Dec 16, 2024
1 parent 0355b12 commit 2d74cf5
Show file tree
Hide file tree
Showing 3 changed files with 110 additions and 0 deletions.
11 changes: 11 additions & 0 deletions src/backend/distributed/planner/query_pushdown_planning.c
Original file line number Diff line number Diff line change
Expand Up @@ -2049,6 +2049,17 @@ CreateSubqueryTargetListAndAdjustVars(List *columnList)
*/
column->varno = 1;
column->varattno = resNo;

/*
* With Postgres 16+, we need to ensure that column's varnullingrels - the set
* of join rels that can null the var - is empty. This is because there is one
* one range table entry in the query being constructed by subquery pushdown
* so a non-empty varnullingrels would be incorrect, and confuse the Postgres
* planner as in #7787.
*/
#if PG_VERSION_NUM >= PG_VERSION_16
column->varnullingrels = NULL;

Check warning on line 2061 in src/backend/distributed/planner/query_pushdown_planning.c

View check run for this annotation

Codecov / codecov/patch

src/backend/distributed/planner/query_pushdown_planning.c#L2061

Added line #L2061 was not covered by tests
#endif
}

return subqueryTargetEntryList;
Expand Down
82 changes: 82 additions & 0 deletions src/test/regress/expected/issue_7705.out
Original file line number Diff line number Diff line change
Expand Up @@ -241,6 +241,88 @@ ORDER BY t1.id;
Output: t1.id
(22 rows)

-- Issue #7787
SELECT COUNT(DISTINCT a2)
FROM t1 LEFT OUTER JOIN t2 ON t1.id = t2.account_id;
count
---------------------------------------------------------------------
2
(1 row)

EXPLAIN (VERBOSE, COSTS OFF, TIMING OFF)
SELECT COUNT(DISTINCT a2)
FROM t1 LEFT OUTER JOIN t2 ON t1.id = t2.account_id;
QUERY PLAN
---------------------------------------------------------------------
Aggregate
Output: count(DISTINCT remote_scan.count)
-> Sort
Output: remote_scan.count
Sort Key: remote_scan.count
-> Custom Scan (Citus Adaptive)
Output: remote_scan.count
Task Count: 4
Tasks Shown: One of 4
-> Task
Query: SELECT worker_column_1 AS count FROM (SELECT t2.a2 AS worker_column_1 FROM (issue_7705.t1_30070000 t1 LEFT JOIN issue_7705.t2_30070004 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.account_id)))) worker_subquery GROUP BY worker_column_1
Node: host=localhost port=xxxxx dbname=regression
-> HashAggregate
Output: t2.a2
Group Key: t2.a2
-> Hash Right Join
Output: t2.a2
Inner Unique: true
Hash Cond: (t2.account_id = t1.id)
-> Seq Scan on issue_7705.t2_30070004 t2
Output: t2.id, t2.account_id, t2.a2
-> Hash
Output: t1.id
-> Seq Scan on issue_7705.t1_30070000 t1
Output: t1.id
(25 rows)

SELECT 1
FROM t1 LEFT OUTER JOIN t2 ON t1.id = t2.account_id
HAVING COUNT(DISTINCT a2) > 1;
?column?
---------------------------------------------------------------------
1
(1 row)

EXPLAIN (VERBOSE, COSTS OFF, TIMING OFF)
SELECT 1
FROM t1 LEFT OUTER JOIN t2 ON t1.id = t2.account_id
HAVING COUNT(DISTINCT a2) > 1;
QUERY PLAN
---------------------------------------------------------------------
Aggregate
Output: remote_scan."?column?"
Filter: (count(DISTINCT remote_scan.worker_column_2) > 1)
-> Sort
Output: remote_scan."?column?", remote_scan.worker_column_2
Sort Key: remote_scan.worker_column_2
-> Custom Scan (Citus Adaptive)
Output: remote_scan."?column?", remote_scan.worker_column_2
Task Count: 4
Tasks Shown: One of 4
-> Task
Query: SELECT 1, worker_column_1 AS worker_column_2 FROM (SELECT t2.a2 AS worker_column_1 FROM (issue_7705.t1_30070000 t1 LEFT JOIN issue_7705.t2_30070004 t2 ON ((t1.id OPERATOR(pg_catalog.=) t2.account_id)))) worker_subquery GROUP BY worker_column_1
Node: host=localhost port=xxxxx dbname=regression
-> HashAggregate
Output: 1, t2.a2
Group Key: t2.a2
-> Hash Right Join
Output: t2.a2
Inner Unique: true
Hash Cond: (t2.account_id = t1.id)
-> Seq Scan on issue_7705.t2_30070004 t2
Output: t2.id, t2.account_id, t2.a2
-> Hash
Output: t1.id
-> Seq Scan on issue_7705.t1_30070000 t1
Output: t1.id
(26 rows)

--- cleanup
\set VERBOSITY TERSE
DROP SCHEMA issue_7705 CASCADE;
Expand Down
17 changes: 17 additions & 0 deletions src/test/regress/sql/issue_7705.sql
Original file line number Diff line number Diff line change
Expand Up @@ -66,6 +66,23 @@ SELECT t1.id, CASE nextval('test_seq') %2 = 0 WHEN true THEN t2.a2 ELSE 1 END
FROM t1 LEFT OUTER JOIN t2 ON t1.id = t2.account_id
ORDER BY t1.id;


-- Issue #7787

SELECT COUNT(DISTINCT a2)
FROM t1 LEFT OUTER JOIN t2 ON t1.id = t2.account_id;
EXPLAIN (VERBOSE, COSTS OFF, TIMING OFF)
SELECT COUNT(DISTINCT a2)
FROM t1 LEFT OUTER JOIN t2 ON t1.id = t2.account_id;

SELECT 1
FROM t1 LEFT OUTER JOIN t2 ON t1.id = t2.account_id
HAVING COUNT(DISTINCT a2) > 1;
EXPLAIN (VERBOSE, COSTS OFF, TIMING OFF)
SELECT 1
FROM t1 LEFT OUTER JOIN t2 ON t1.id = t2.account_id
HAVING COUNT(DISTINCT a2) > 1;

--- cleanup
\set VERBOSITY TERSE
DROP SCHEMA issue_7705 CASCADE;
Expand Down

0 comments on commit 2d74cf5

Please sign in to comment.