From 3cf8686014f91174018f20e01dbb0dafdcad0473 Mon Sep 17 00:00:00 2001 From: Tom Lane Date: Sat, 25 Apr 2015 16:44:27 -0400 Subject: [PATCH] Prevent improper reordering of antijoins vs. outer joins. An outer join appearing within the RHS of an antijoin can't commute with the antijoin, but somehow I missed teaching make_outerjoininfo() about that. In Teodor Sigaev's recent trouble report, this manifests as a "could not find RelOptInfo for given relids" error within eqjoinsel(); but I think silently wrong query results are possible too, if the planner misorders the joins and doesn't happen to trigger any internal consistency checks. It's broken as far back as we had antijoins, so back-patch to all supported branches. --- src/backend/optimizer/plan/initsplan.c | 7 +++-- src/test/regress/expected/join.out | 42 ++++++++++++++++++++++++++ src/test/regress/sql/join.sql | 17 +++++++++++ 3 files changed, 63 insertions(+), 3 deletions(-) diff --git a/src/backend/optimizer/plan/initsplan.c b/src/backend/optimizer/plan/initsplan.c index a7655e4a71..00b2625d34 100644 --- a/src/backend/optimizer/plan/initsplan.c +++ b/src/backend/optimizer/plan/initsplan.c @@ -1165,9 +1165,9 @@ make_outerjoininfo(PlannerInfo *root, * For a lower OJ in our RHS, if our join condition does not use the * lower join's RHS and the lower OJ's join condition is strict, we * can interchange the ordering of the two OJs; otherwise we must add - * lower OJ's full syntactic relset to min_righthand. Here, we must - * preserve ordering anyway if either the current join is a semijoin, - * or the lower OJ is either a semijoin or an antijoin. + * the lower OJ's full syntactic relset to min_righthand. Also, we + * must preserve ordering anyway if either the current join or the + * lower OJ is either a semijoin or an antijoin. * * Here, we have to consider that "our join condition" includes any * clauses that syntactically appeared above the lower OJ and below @@ -1184,6 +1184,7 @@ make_outerjoininfo(PlannerInfo *root, { if (bms_overlap(clause_relids, otherinfo->syn_righthand) || jointype == JOIN_SEMI || + jointype == JOIN_ANTI || otherinfo->jointype == JOIN_SEMI || otherinfo->jointype == JOIN_ANTI || !otherinfo->lhs_strict || otherinfo->delay_upper_joins) diff --git a/src/test/regress/expected/join.out b/src/test/regress/expected/join.out index e4f3f22e0b..ed9ad0e135 100644 --- a/src/test/regress/expected/join.out +++ b/src/test/regress/expected/join.out @@ -2283,6 +2283,48 @@ WHERE d.f1 IS NULL; 9999 (3 rows) +-- +-- regression test for proper handling of outer joins within antijoins +-- +create temp table tt4x(c1 int, c2 int, c3 int); +explain (costs off) +select * from tt4x t1 +where not exists ( + select 1 from tt4x t2 + left join tt4x t3 on t2.c3 = t3.c1 + left join ( select t5.c1 as c1 + from tt4x t4 left join tt4x t5 on t4.c2 = t5.c1 + ) a1 on t3.c2 = a1.c1 + where t1.c1 = t2.c2 +); + QUERY PLAN +--------------------------------------------------------- + Hash Anti Join + Hash Cond: (t1.c1 = t2.c2) + -> Seq Scan on tt4x t1 + -> Hash + -> Merge Right Join + Merge Cond: (t5.c1 = t3.c2) + -> Merge Join + Merge Cond: (t4.c2 = t5.c1) + -> Sort + Sort Key: t4.c2 + -> Seq Scan on tt4x t4 + -> Sort + Sort Key: t5.c1 + -> Seq Scan on tt4x t5 + -> Sort + Sort Key: t3.c2 + -> Merge Left Join + Merge Cond: (t2.c3 = t3.c1) + -> Sort + Sort Key: t2.c3 + -> Seq Scan on tt4x t2 + -> Sort + Sort Key: t3.c1 + -> Seq Scan on tt4x t3 +(24 rows) + -- -- regression test for problems of the sort depicted in bug #3494 -- diff --git a/src/test/regress/sql/join.sql b/src/test/regress/sql/join.sql index d0cf0a041d..5b65ea8c92 100644 --- a/src/test/regress/sql/join.sql +++ b/src/test/regress/sql/join.sql @@ -447,6 +447,23 @@ LEFT JOIN ( ) AS d ON (a.f1 = d.f1) WHERE d.f1 IS NULL; +-- +-- regression test for proper handling of outer joins within antijoins +-- + +create temp table tt4x(c1 int, c2 int, c3 int); + +explain (costs off) +select * from tt4x t1 +where not exists ( + select 1 from tt4x t2 + left join tt4x t3 on t2.c3 = t3.c1 + left join ( select t5.c1 as c1 + from tt4x t4 left join tt4x t5 on t4.c2 = t5.c1 + ) a1 on t3.c2 = a1.c1 + where t1.c1 = t2.c2 +); + -- -- regression test for problems of the sort depicted in bug #3494 --