* Portions Copyright (c) 1994, Regents of the University of California
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/backend/nodes/copyfuncs.c,v 1.353 2006/11/05 22:42:08 tgl Exp $
+ * $PostgreSQL: pgsql/src/backend/nodes/copyfuncs.c,v 1.353.2.1 2007/05/22 23:24:08 tgl Exp $
*
*-------------------------------------------------------------------------
*/
COPY_BITMAPSET_FIELD(min_righthand);
COPY_SCALAR_FIELD(is_full_join);
COPY_SCALAR_FIELD(lhs_strict);
+ COPY_SCALAR_FIELD(delay_upper_joins);
return newnode;
}
* Portions Copyright (c) 1994, Regents of the University of California
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/backend/nodes/equalfuncs.c,v 1.287 2006/11/05 22:42:08 tgl Exp $
+ * $PostgreSQL: pgsql/src/backend/nodes/equalfuncs.c,v 1.287.2.1 2007/05/22 23:24:08 tgl Exp $
*
*-------------------------------------------------------------------------
*/
COMPARE_BITMAPSET_FIELD(min_righthand);
COMPARE_SCALAR_FIELD(is_full_join);
COMPARE_SCALAR_FIELD(lhs_strict);
+ COMPARE_SCALAR_FIELD(delay_upper_joins);
return true;
}
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/backend/nodes/outfuncs.c,v 1.285.2.1 2007/05/22 01:40:42 tgl Exp $
+ * $PostgreSQL: pgsql/src/backend/nodes/outfuncs.c,v 1.285.2.2 2007/05/22 23:24:08 tgl Exp $
*
* NOTES
* Every node type that can appear in stored rules' parsetrees *must*
WRITE_BITMAPSET_FIELD(min_righthand);
WRITE_BOOL_FIELD(is_full_join);
WRITE_BOOL_FIELD(lhs_strict);
+ WRITE_BOOL_FIELD(delay_upper_joins);
}
static void
*
*
* IDENTIFICATION
- * $PostgreSQL: pgsql/src/backend/optimizer/plan/initsplan.c,v 1.123.2.4 2007/02/16 20:57:26 tgl Exp $
+ * $PostgreSQL: pgsql/src/backend/optimizer/plan/initsplan.c,v 1.123.2.5 2007/05/22 23:24:08 tgl Exp $
*
*-------------------------------------------------------------------------
*/
errmsg("SELECT FOR UPDATE/SHARE cannot be applied to the nullable side of an outer join")));
}
+ /* this always starts out false */
+ ojinfo->delay_upper_joins = false;
+
/* If it's a full join, no need to be very smart */
ojinfo->is_full_join = is_full_join;
if (is_full_join)
* lower join's RHS and the lower OJ's join condition is strict, we
* can interchange the ordering of the two OJs, so exclude the lower
* RHS from our min_righthand.
+ *
+ * Here, we have to consider that "our join condition" includes
+ * any clauses that syntactically appeared above the lower OJ and
+ * below ours; those are equivalent to degenerate clauses in our
+ * OJ and must be treated as such. Such clauses obviously can't
+ * reference our LHS, and they must be non-strict for the lower OJ's
+ * RHS (else reduce_outer_joins would have reduced the lower OJ to
+ * a plain join). Hence the other ways in which we handle clauses
+ * within our join condition are not affected by them. The net
+ * effect is therefore sufficiently represented by the
+ * delay_upper_joins flag saved for us by distribute_qual_to_rels.
*/
if (bms_overlap(ojinfo->min_righthand, otherinfo->min_righthand) &&
!bms_overlap(clause_relids, otherinfo->min_righthand) &&
- otherinfo->lhs_strict)
+ otherinfo->lhs_strict && !otherinfo->delay_upper_joins)
{
ojinfo->min_righthand = bms_del_members(ojinfo->min_righthand,
otherinfo->min_righthand);
/* we'll need another iteration */
found_some = true;
}
+ /* set delay_upper_joins if needed */
+ if (!ojinfo->is_full_join &&
+ bms_overlap(relids, ojinfo->min_lefthand))
+ ojinfo->delay_upper_joins = true;
}
}
} while (found_some);
* Portions Copyright (c) 1996-2006, PostgreSQL Global Development Group
* Portions Copyright (c) 1994, Regents of the University of California
*
- * $PostgreSQL: pgsql/src/include/nodes/relation.h,v 1.128.2.2 2007/05/22 01:40:42 tgl Exp $
+ * $PostgreSQL: pgsql/src/include/nodes/relation.h,v 1.128.2.3 2007/05/22 23:24:09 tgl Exp $
*
*-------------------------------------------------------------------------
*/
* It is not valid for either min_lefthand or min_righthand to be empty sets;
* if they were, this would break the logic that enforces join order.
*
+ * delay_upper_joins is set TRUE if we detect a pushed-down clause that has
+ * to be evaluated after this join is formed (because it references the RHS).
+ * Any outer joins that have such a clause and this join in their RHS cannot
+ * commute with this join, because that would leave noplace to check the
+ * pushed-down clause. (We don't track this for FULL JOINs, either.)
+ *
* Note: OuterJoinInfo directly represents only LEFT JOIN and FULL JOIN;
* RIGHT JOIN is handled by switching the inputs to make it a LEFT JOIN.
* We make an OuterJoinInfo for FULL JOINs even though there is no flexibility
Relids min_righthand; /* base relids in minimum RHS for join */
bool is_full_join; /* it's a FULL OUTER JOIN */
bool lhs_strict; /* joinclause is strict for some LHS rel */
+ bool delay_upper_joins; /* can't commute with upper RHS */
} OuterJoinInfo;
/*
2 | | |
(3 rows)
+reset enable_hashjoin;
+reset enable_nestloop;
+--
+-- regression test for 8.2 bug with improper re-ordering of left joins
+--
+create temp table tt3(f1 int, f2 text);
+insert into tt3 select x, repeat('xyzzy', 100) from generate_series(1,10000) x;
+create index tt3i on tt3(f1);
+analyze tt3;
+create temp table tt4(f1 int);
+insert into tt4 values (0),(1),(9999);
+analyze tt4;
+SELECT a.f1
+FROM tt4 a
+LEFT JOIN (
+ SELECT b.f1
+ FROM tt3 b LEFT JOIN tt3 c ON (b.f1 = c.f1)
+ WHERE c.f1 IS NULL
+) AS d ON (a.f1 = d.f1)
+WHERE d.f1 IS NULL;
+ f1
+------
+ 0
+ 1
+ 9999
+(3 rows)
+
2 | | |
(3 rows)
+reset enable_hashjoin;
+reset enable_nestloop;
+--
+-- regression test for 8.2 bug with improper re-ordering of left joins
+--
+create temp table tt3(f1 int, f2 text);
+insert into tt3 select x, repeat('xyzzy', 100) from generate_series(1,10000) x;
+create index tt3i on tt3(f1);
+analyze tt3;
+create temp table tt4(f1 int);
+insert into tt4 values (0),(1),(9999);
+analyze tt4;
+SELECT a.f1
+FROM tt4 a
+LEFT JOIN (
+ SELECT b.f1
+ FROM tt3 b LEFT JOIN tt3 c ON (b.f1 = c.f1)
+ WHERE c.f1 IS NULL
+) AS d ON (a.f1 = d.f1)
+WHERE d.f1 IS NULL;
+ f1
+------
+ 0
+ 1
+ 9999
+(3 rows)
+
select tt1.*, tt2.* from tt1 left join tt2 on tt1.joincol = tt2.joincol;
select tt1.*, tt2.* from tt2 right join tt1 on tt1.joincol = tt2.joincol;
+
+reset enable_hashjoin;
+reset enable_nestloop;
+
+--
+-- regression test for 8.2 bug with improper re-ordering of left joins
+--
+
+create temp table tt3(f1 int, f2 text);
+insert into tt3 select x, repeat('xyzzy', 100) from generate_series(1,10000) x;
+create index tt3i on tt3(f1);
+analyze tt3;
+
+create temp table tt4(f1 int);
+insert into tt4 values (0),(1),(9999);
+analyze tt4;
+
+SELECT a.f1
+FROM tt4 a
+LEFT JOIN (
+ SELECT b.f1
+ FROM tt3 b LEFT JOIN tt3 c ON (b.f1 = c.f1)
+ WHERE c.f1 IS NULL
+) AS d ON (a.f1 = d.f1)
+WHERE d.f1 IS NULL;