Commit 7d4a10e2 authored by Tom Lane's avatar Tom Lane

Use PlaceHolderVars within the quals of a FULL JOIN.

This prevents failures in cases where we pull up a constant or var-free
expression from a subquery and put it into a full join's qual.  That can
result in not recognizing the qual as containing a mergejoin-able or
hashjoin-able condition.  A PHV prevents the problem because it is still
recognized as belonging to the side of the join the subquery is in.

I'm not very sure about the net effect of this change on plan quality.
In "typical" cases where the join keys are Vars, nothing changes.
In an affected case, the PHV-wrapped expression is less likely to be seen
as equal to PHV-less instances below the join, but more likely to be seen
as equal to similar expressions above the join, so it may end up being a
wash.  In the one existing case where there's any visible change in a
regression-test plan, it amounts to referencing a lower computation of a
COALESCE result instead of recomputing it, which seems like a win.

Given my uncertainty about that and the lack of field complaints,
no back-patch, even though this is a very ancient problem.

Discussion: https://postgr.es/m/32090.1539378124@sss.pgh.pa.us
parent e9f42d52
...@@ -2044,6 +2044,18 @@ replace_vars_in_jointree(Node *jtnode, ...@@ -2044,6 +2044,18 @@ replace_vars_in_jointree(Node *jtnode,
} }
replace_vars_in_jointree(j->larg, context, lowest_nulling_outer_join); replace_vars_in_jointree(j->larg, context, lowest_nulling_outer_join);
replace_vars_in_jointree(j->rarg, context, lowest_nulling_outer_join); replace_vars_in_jointree(j->rarg, context, lowest_nulling_outer_join);
/*
* Use PHVs within the join quals of a full join, even when it's the
* lowest nulling outer join. Otherwise, we cannot identify which
* side of the join a pulled-up var-free expression came from, which
* can lead to failure to make a plan at all because none of the quals
* appear to be mergeable or hashable conditions. For this purpose we
* don't care about the state of wrap_non_vars, so leave it alone.
*/
if (j->jointype == JOIN_FULL)
context->need_phvs = true;
j->quals = pullup_replace_vars(j->quals, context); j->quals = pullup_replace_vars(j->quals, context);
/* /*
......
...@@ -2024,6 +2024,20 @@ NATURAL FULL JOIN ...@@ -2024,6 +2024,20 @@ NATURAL FULL JOIN
ee | | 42 | 2 | ee | | 42 | 2 |
(4 rows) (4 rows)
-- Constants as join keys can also be problematic
SELECT * FROM
(SELECT name, n as s1_n FROM t1) as s1
FULL JOIN
(SELECT name, 2 as s2_n FROM t2) as s2
ON (s1_n = s2_n);
name | s1_n | name | s2_n
------+------+------+------
| | bb | 2
| | cc | 2
| | ee | 2
bb | 11 | |
(4 rows)
-- Test for propagation of nullability constraints into sub-joins -- Test for propagation of nullability constraints into sub-joins
create temp table x (x1 int, x2 int); create temp table x (x1 int, x2 int);
insert into x values (1,11); insert into x values (1,11);
...@@ -2854,7 +2868,7 @@ SELECT qq, unique1 ...@@ -2854,7 +2868,7 @@ SELECT qq, unique1
--------------------------------------------------------------------------------------------------------- ---------------------------------------------------------------------------------------------------------
Nested Loop Nested Loop
-> Hash Full Join -> Hash Full Join
Hash Cond: (COALESCE(a.q1, '0'::bigint) = COALESCE(b.q2, '-1'::bigint)) Hash Cond: ((COALESCE(a.q1, '0'::bigint)) = (COALESCE(b.q2, '-1'::bigint)))
-> Seq Scan on int8_tbl a -> Seq Scan on int8_tbl a
-> Hash -> Hash
-> Seq Scan on int8_tbl b -> Seq Scan on int8_tbl b
......
...@@ -297,6 +297,13 @@ NATURAL FULL JOIN ...@@ -297,6 +297,13 @@ NATURAL FULL JOIN
(SELECT name, n as s3_n FROM t3) as s3 (SELECT name, n as s3_n FROM t3) as s3
) ss2; ) ss2;
-- Constants as join keys can also be problematic
SELECT * FROM
(SELECT name, n as s1_n FROM t1) as s1
FULL JOIN
(SELECT name, 2 as s2_n FROM t2) as s2
ON (s1_n = s2_n);
-- Test for propagation of nullability constraints into sub-joins -- Test for propagation of nullability constraints into sub-joins
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment