]> granicus.if.org Git - postgresql/commitdiff
Fix incorrect handling of join clauses pushed into parameterized paths.
authorTom Lane <tgl@sss.pgh.pa.us>
Thu, 19 Apr 2018 19:49:12 +0000 (15:49 -0400)
committerTom Lane <tgl@sss.pgh.pa.us>
Thu, 19 Apr 2018 19:49:12 +0000 (15:49 -0400)
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

src/backend/optimizer/plan/createplan.c
src/backend/optimizer/util/restrictinfo.c
src/include/optimizer/restrictinfo.h
src/test/regress/expected/join.out
src/test/regress/sql/join.sql

index 50b56e111d89b95a2dd15b0e5d1cd70f45639d2b..f50fdc2d2a8aec963581d7ed8c9bb171e0664074 100644 (file)
@@ -3685,6 +3685,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
@@ -3798,6 +3799,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
@@ -4090,6 +4092,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
index ebae0cd8ce0345a7e4a38e5db287229bd5fb303e..fd66c1303db4fc33f95f603856f296da967ade5f 100644 (file)
@@ -379,6 +379,7 @@ extract_actual_clauses(List *restrictinfo_list,
  */
 void
 extract_actual_join_clauses(List *restrictinfo_list,
+                                                       Relids joinrelids,
                                                        List **joinquals,
                                                        List **otherquals)
 {
@@ -391,7 +392,15 @@ extract_actual_join_clauses(List *restrictinfo_list,
        {
                RestrictInfo *rinfo = lfirst_node(RestrictInfo, l);
 
-               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);
index b2a69998fd84a823ef41e5e8ea2ccb755c281230..d8d2079f0ededbc1a15f9624ca758d8c53e1c2c5 100644 (file)
@@ -36,6 +36,7 @@ extern List *get_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);
index 5b6dd399163a70defb32835e5a1f8aebca2a2d93..1a91e0adafbe06de92bda5023de58926a24fe905 100644 (file)
@@ -3349,6 +3349,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
 --
index 350d44c8c50302f344375148a81a2c7829fe66f7..be651ec302f8aec315360abe7d592deb97ca1eee 100644 (file)
@@ -1019,6 +1019,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
 --