mirror of
https://git.postgresql.org/git/postgresql.git
synced 2025-02-23 19:39:53 +08:00
Fix incorrect handling of join clauses pushed into parameterized paths.
In some cases a clause attached to an outer join can be pushed down into the outer join's RHS even though the clause is not degenerate --- this can happen if we choose to make a parameterized path for the RHS. If the clause ends up attached to a lower outer join, we'd misclassify it as being a "join filter" not a plain "filter" condition at that node, leading to wrong query results. To fix, teach extract_actual_join_clauses to examine each join clause's required_relids, not just its is_pushed_down flag. (The latter now seems vestigial, or at least in need of rethinking, but we won't do anything so invasive as redefining it in a bug-fix patch.) This has been wrong since we introduced parameterized paths in 9.2, though it's evidently hard to hit given the lack of previous reports. The test case used here involves a lateral function call, and I think that a lateral reference may be required to get the planner to select a broken plan; though I wouldn't swear to that. In any case, even if LATERAL is needed to trigger the bug, it still affects all supported branches, so back-patch to all. Per report from Andreas Karlsson. Thanks to Andrew Gierth for preliminary investigation. Discussion: https://postgr.es/m/f8128b11-c5bf-3539-48cd-234178b2314d@proxel.se
This commit is contained in:
parent
070179a4a2
commit
e1d4398c0a
@ -2071,6 +2071,7 @@ create_nestloop_plan(PlannerInfo *root,
|
||||
if (IS_OUTER_JOIN(best_path->jointype))
|
||||
{
|
||||
extract_actual_join_clauses(joinrestrictclauses,
|
||||
best_path->path.parent->relids,
|
||||
&joinclauses, &otherclauses);
|
||||
}
|
||||
else
|
||||
@ -2171,6 +2172,7 @@ create_mergejoin_plan(PlannerInfo *root,
|
||||
if (IS_OUTER_JOIN(best_path->jpath.jointype))
|
||||
{
|
||||
extract_actual_join_clauses(joinclauses,
|
||||
best_path->jpath.path.parent->relids,
|
||||
&joinclauses, &otherclauses);
|
||||
}
|
||||
else
|
||||
@ -2454,6 +2456,7 @@ create_hashjoin_plan(PlannerInfo *root,
|
||||
if (IS_OUTER_JOIN(best_path->jpath.jointype))
|
||||
{
|
||||
extract_actual_join_clauses(joinclauses,
|
||||
best_path->jpath.path.parent->relids,
|
||||
&joinclauses, &otherclauses);
|
||||
}
|
||||
else
|
||||
|
@ -605,6 +605,7 @@ extract_actual_clauses(List *restrictinfo_list,
|
||||
*/
|
||||
void
|
||||
extract_actual_join_clauses(List *restrictinfo_list,
|
||||
Relids joinrelids,
|
||||
List **joinquals,
|
||||
List **otherquals)
|
||||
{
|
||||
@ -619,7 +620,15 @@ extract_actual_join_clauses(List *restrictinfo_list,
|
||||
|
||||
Assert(IsA(rinfo, RestrictInfo));
|
||||
|
||||
if (rinfo->is_pushed_down)
|
||||
/*
|
||||
* We must check both is_pushed_down and required_relids, since an
|
||||
* outer-join clause that's been pushed down to some lower join level
|
||||
* via path parameterization will not be marked is_pushed_down;
|
||||
* nonetheless, it must be treated as a filter clause not a join
|
||||
* clause so far as the lower join level is concerned.
|
||||
*/
|
||||
if (rinfo->is_pushed_down ||
|
||||
!bms_is_subset(rinfo->required_relids, joinrelids))
|
||||
{
|
||||
if (!rinfo->pseudoconstant)
|
||||
*otherquals = lappend(*otherquals, rinfo->clause);
|
||||
|
@ -39,6 +39,7 @@ extern List *get_all_actual_clauses(List *restrictinfo_list);
|
||||
extern List *extract_actual_clauses(List *restrictinfo_list,
|
||||
bool pseudoconstant);
|
||||
extern void extract_actual_join_clauses(List *restrictinfo_list,
|
||||
Relids joinrelids,
|
||||
List **joinquals,
|
||||
List **otherquals);
|
||||
extern bool join_clause_is_movable_to(RestrictInfo *rinfo, RelOptInfo *baserel);
|
||||
|
@ -3207,6 +3207,33 @@ order by fault;
|
||||
| 123 | 122
|
||||
(1 row)
|
||||
|
||||
explain (costs off)
|
||||
select * from
|
||||
(values (1, array[10,20]), (2, array[20,30])) as v1(v1x,v1ys)
|
||||
left join (values (1, 10), (2, 20)) as v2(v2x,v2y) on v2x = v1x
|
||||
left join unnest(v1ys) as u1(u1y) on u1y = v2y;
|
||||
QUERY PLAN
|
||||
-------------------------------------------------------------
|
||||
Nested Loop Left Join
|
||||
-> Values Scan on "*VALUES*"
|
||||
-> Hash Right Join
|
||||
Hash Cond: (u1.u1y = "*VALUES*_1".column2)
|
||||
Filter: ("*VALUES*_1".column1 = "*VALUES*".column1)
|
||||
-> Function Scan on unnest u1
|
||||
-> Hash
|
||||
-> Values Scan on "*VALUES*_1"
|
||||
(8 rows)
|
||||
|
||||
select * from
|
||||
(values (1, array[10,20]), (2, array[20,30])) as v1(v1x,v1ys)
|
||||
left join (values (1, 10), (2, 20)) as v2(v2x,v2y) on v2x = v1x
|
||||
left join unnest(v1ys) as u1(u1y) on u1y = v2y;
|
||||
v1x | v1ys | v2x | v2y | u1y
|
||||
-----+---------+-----+-----+-----
|
||||
1 | {10,20} | 1 | 10 | 10
|
||||
2 | {20,30} | 2 | 20 | 20
|
||||
(2 rows)
|
||||
|
||||
--
|
||||
-- test handling of potential equivalence clauses above outer joins
|
||||
--
|
||||
|
@ -971,6 +971,17 @@ select * from
|
||||
where fault = 122
|
||||
order by fault;
|
||||
|
||||
explain (costs off)
|
||||
select * from
|
||||
(values (1, array[10,20]), (2, array[20,30])) as v1(v1x,v1ys)
|
||||
left join (values (1, 10), (2, 20)) as v2(v2x,v2y) on v2x = v1x
|
||||
left join unnest(v1ys) as u1(u1y) on u1y = v2y;
|
||||
|
||||
select * from
|
||||
(values (1, array[10,20]), (2, array[20,30])) as v1(v1x,v1ys)
|
||||
left join (values (1, 10), (2, 20)) as v2(v2x,v2y) on v2x = v1x
|
||||
left join unnest(v1ys) as u1(u1y) on u1y = v2y;
|
||||
|
||||
--
|
||||
-- test handling of potential equivalence clauses above outer joins
|
||||
--
|
||||
|
Loading…
Reference in New Issue
Block a user