From e67d5767ae85606f99d696874d53388bac6543b7 Mon Sep 17 00:00:00 2001 From: "Andrey V. Lepikhov" Date: Wed, 6 Jul 2022 15:36:19 +0300 Subject: [PATCH 2/6] Introudce ec_filters in EquivalenceClass struct, the semantics is the quals can be applied to any EquivalenceMember in this EC. Later this information is used to generate new RestrictInfo and was distributed to related RelOptInfo very soon. There are 3 major steps here: a). In distribute_qual_to_rels to gather the ineq quallist. b). After deconstruct_jointree, distribute_filter_quals_to_eclass distribute these ineq-quallist to the related EC's ef_filters. c). generate_base_implied_equalities_no_const scan the ec_filters and distriubte the restrictinfo to related RelOptInfo. Author: David Rowley at 2015-12 [1] Andy Fan rebases this patch to current latest code. --- .../postgres_fdw/expected/postgres_fdw.out | 36 ++-- src/backend/nodes/outfuncs.c | 14 ++ src/backend/optimizer/path/equivclass.c | 182 ++++++++++++++++++ src/backend/optimizer/plan/initsplan.c | 96 +++++++-- src/backend/utils/cache/lsyscache.c | 28 +++ src/include/nodes/nodes.h | 1 + src/include/nodes/pathnodes.h | 37 ++++ src/include/optimizer/paths.h | 1 + src/include/utils/lsyscache.h | 1 + src/test/regress/expected/equivclass.out | 45 ++++- src/test/regress/expected/join.out | 22 +-- src/test/regress/expected/merge.out | 16 +- src/test/regress/expected/partition_join.out | 43 +++-- src/test/regress/sql/equivclass.sql | 12 ++ 14 files changed, 460 insertions(+), 74 deletions(-) diff --git a/contrib/postgres_fdw/expected/postgres_fdw.out b/contrib/postgres_fdw/expected/postgres_fdw.out index 44457f930c..2758049f5b 100644 --- a/contrib/postgres_fdw/expected/postgres_fdw.out +++ b/contrib/postgres_fdw/expected/postgres_fdw.out @@ -1545,12 +1545,12 @@ SELECT t1.c1, ss.a, ss.b FROM (SELECT c1 FROM "S 1"."T 3" WHERE c1 = 50) t1 INNE -- full outer join + inner join EXPLAIN (VERBOSE, COSTS OFF) SELECT t1.c1, t2.c1, t3.c1 FROM ft4 t1 INNER JOIN ft5 t2 ON (t1.c1 = t2.c1 + 1 and t1.c1 between 50 and 60) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) ORDER BY t1.c1, t2.c1, t3.c1 LIMIT 10; - QUERY PLAN ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + QUERY PLAN +---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- Foreign Scan Output: t1.c1, t2.c1, t3.c1 Relations: ((public.ft4 t1) INNER JOIN (public.ft5 t2)) FULL JOIN (public.ft4 t3) - Remote SQL: SELECT r1.c1, r2.c1, r4.c1 FROM (("S 1"."T 3" r1 INNER JOIN "S 1"."T 4" r2 ON (((r1.c1 = (r2.c1 + 1))) AND ((r1.c1 >= 50)) AND ((r1.c1 <= 60)))) FULL JOIN "S 1"."T 3" r4 ON (((r2.c1 = r4.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST, r4.c1 ASC NULLS LAST LIMIT 10::bigint + Remote SQL: SELECT r1.c1, r2.c1, r4.c1 FROM (("S 1"."T 3" r1 INNER JOIN "S 1"."T 4" r2 ON (((r1.c1 = (r2.c1 + 1))) AND (((r2.c1 + 1) >= 50)) AND (((r2.c1 + 1) <= 60)) AND ((r1.c1 >= 50)) AND ((r1.c1 <= 60)))) FULL JOIN "S 1"."T 3" r4 ON (((r2.c1 = r4.c1)))) ORDER BY r1.c1 ASC NULLS LAST, r2.c1 ASC NULLS LAST, r4.c1 ASC NULLS LAST LIMIT 10::bigint (4 rows) SELECT t1.c1, t2.c1, t3.c1 FROM ft4 t1 INNER JOIN ft5 t2 ON (t1.c1 = t2.c1 + 1 and t1.c1 between 50 and 60) FULL JOIN ft4 t3 ON (t2.c1 = t3.c1) ORDER BY t1.c1, t2.c1, t3.c1 LIMIT 10; @@ -2335,12 +2335,12 @@ SELECT ft4.c1, q.* FROM ft4 LEFT JOIN (SELECT 13, ft1.c1, ft2.c1 FROM ft1 RIGHT UPDATE ft5 SET c3 = null where c1 % 9 = 0; EXPLAIN (VERBOSE, COSTS OFF) SELECT ft5, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2 FROM ft5 left join ft4 on ft5.c1 = ft4.c1 WHERE ft4.c1 BETWEEN 10 and 30 ORDER BY ft5.c1, ft4.c1; - QUERY PLAN ---------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + QUERY PLAN +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- Foreign Scan Output: ft5.*, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2 Relations: (public.ft5) INNER JOIN (public.ft4) - Remote SQL: SELECT CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1.c1, r1.c2, r1.c3) END, r1.c1, r1.c2, r1.c3, r2.c1, r2.c2 FROM ("S 1"."T 4" r1 INNER JOIN "S 1"."T 3" r2 ON (((r1.c1 = r2.c1)) AND ((r2.c1 >= 10)) AND ((r2.c1 <= 30)))) ORDER BY r1.c1 ASC NULLS LAST + Remote SQL: SELECT CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1.c1, r1.c2, r1.c3) END, r1.c1, r1.c2, r1.c3, r2.c1, r2.c2 FROM ("S 1"."T 4" r1 INNER JOIN "S 1"."T 3" r2 ON (((r1.c1 = r2.c1)) AND ((r2.c1 >= 10)) AND ((r2.c1 <= 30)) AND ((r1.c1 >= 10)) AND ((r1.c1 <= 30)))) ORDER BY r1.c1 ASC NULLS LAST (4 rows) SELECT ft5, ft5.c1, ft5.c2, ft5.c3, ft4.c1, ft4.c2 FROM ft5 left join ft4 on ft5.c1 = ft4.c1 WHERE ft4.c1 BETWEEN 10 and 30 ORDER BY ft5.c1, ft4.c1; @@ -2362,8 +2362,8 @@ SET enable_hashjoin TO false; EXPLAIN (VERBOSE, COSTS OFF) SELECT * FROM ft1, ft2, ft4, ft5, local_tbl WHERE ft1.c1 = ft2.c1 AND ft1.c2 = ft4.c1 AND ft1.c2 = ft5.c1 AND ft1.c2 = local_tbl.c1 AND ft1.c1 < 100 AND ft2.c1 < 100 FOR UPDATE; - QUERY PLAN --------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- + QUERY PLAN +------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ LockRows Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft4.c1, ft4.c2, ft4.c3, ft5.c1, ft5.c2, ft5.c3, local_tbl.c1, local_tbl.c2, local_tbl.c3, ft1.*, ft2.*, ft4.*, ft5.*, local_tbl.ctid -> Merge Join @@ -2373,7 +2373,7 @@ SELECT * FROM ft1, ft2, ft4, ft5, local_tbl WHERE ft1.c1 = ft2.c1 AND ft1.c2 = f -> Foreign Scan Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*, ft5.c1, ft5.c2, ft5.c3, ft5.* Relations: (((public.ft1) INNER JOIN (public.ft2)) INNER JOIN (public.ft4)) INNER JOIN (public.ft5) - Remote SQL: SELECT r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END, r3.c1, r3.c2, r3.c3, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r4.c1, r4.c2, r4.c3, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4.c1, r4.c2, r4.c3) END FROM ((("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")) AND ((r2."C 1" < 100)) AND ((r1."C 1" < 100)))) INNER JOIN "S 1"."T 3" r3 ON (((r1.c2 = r3.c1)))) INNER JOIN "S 1"."T 4" r4 ON (((r1.c2 = r4.c1)))) ORDER BY r1.c2 ASC NULLS LAST FOR UPDATE OF r1 FOR UPDATE OF r2 FOR UPDATE OF r3 FOR UPDATE OF r4 + Remote SQL: SELECT r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END, r3.c1, r3.c2, r3.c3, CASE WHEN (r3.*)::text IS NOT NULL THEN ROW(r3.c1, r3.c2, r3.c3) END, r4.c1, r4.c2, r4.c3, CASE WHEN (r4.*)::text IS NOT NULL THEN ROW(r4.c1, r4.c2, r4.c3) END FROM ((("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")) AND ((r2."C 1" < 100)) AND ((r2."C 1" < 100)) AND ((r1."C 1" < 100)) AND ((r1."C 1" < 100)))) INNER JOIN "S 1"."T 3" r3 ON (((r1.c2 = r3.c1)))) INNER JOIN "S 1"."T 4" r4 ON (((r1.c2 = r4.c1)))) ORDER BY r1.c2 ASC NULLS LAST FOR UPDATE OF r1 FOR UPDATE OF r2 FOR UPDATE OF r3 FOR UPDATE OF r4 -> Merge Join Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.*, ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.*, ft4.c1, ft4.c2, ft4.c3, ft4.*, ft5.c1, ft5.c2, ft5.c3, ft5.* Merge Cond: (ft1.c2 = ft5.c1) @@ -2391,12 +2391,12 @@ SELECT * FROM ft1, ft2, ft4, ft5, local_tbl WHERE ft1.c1 = ft2.c1 AND ft1.c2 = f Sort Key: ft1.c1 -> Foreign Scan on public.ft1 Output: ft1.c1, ft1.c2, ft1.c3, ft1.c4, ft1.c5, ft1.c6, ft1.c7, ft1.c8, ft1.* - Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100)) FOR UPDATE + Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND (("C 1" < 100)) FOR UPDATE -> Materialize Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.* -> Foreign Scan on public.ft2 Output: ft2.c1, ft2.c2, ft2.c3, ft2.c4, ft2.c5, ft2.c6, ft2.c7, ft2.c8, ft2.* - Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100)) ORDER BY "C 1" ASC NULLS LAST FOR UPDATE + Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" < 100)) AND (("C 1" < 100)) ORDER BY "C 1" ASC NULLS LAST FOR UPDATE -> Sort Output: ft4.c1, ft4.c2, ft4.c3, ft4.* Sort Key: ft4.c1 @@ -5705,25 +5705,25 @@ UPDATE ft2 AS target SET (c2) = ( EXPLAIN (VERBOSE, COSTS OFF) UPDATE ft2 d SET c2 = CASE WHEN random() >= 0 THEN d.c2 ELSE 0 END FROM ft2 AS t WHERE d.c1 = t.c1 AND d.c1 > 1000; - QUERY PLAN ------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------ + QUERY PLAN +----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------- Update on public.ft2 d Remote SQL: UPDATE "S 1"."T 1" SET c2 = $2 WHERE ctid = $1 -> Foreign Scan Output: CASE WHEN (random() >= '0'::double precision) THEN d.c2 ELSE 0 END, d.ctid, d.*, t.* Relations: (public.ft2 d) INNER JOIN (public.ft2 t) - Remote SQL: SELECT r1.c2, r1.ctid, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")) AND ((r1."C 1" > 1000)))) FOR UPDATE OF r1 - -> Hash Join + Remote SQL: SELECT r1.c2, r1.ctid, CASE WHEN (r1.*)::text IS NOT NULL THEN ROW(r1."C 1", r1.c2, r1.c3, r1.c4, r1.c5, r1.c6, r1.c7, r1.c8) END, CASE WHEN (r2.*)::text IS NOT NULL THEN ROW(r2."C 1", r2.c2, r2.c3, r2.c4, r2.c5, r2.c6, r2.c7, r2.c8) END FROM ("S 1"."T 1" r1 INNER JOIN "S 1"."T 1" r2 ON (((r1."C 1" = r2."C 1")) AND ((r2."C 1" > 1000)) AND ((r1."C 1" > 1000)))) FOR UPDATE OF r1 + -> Merge Join Output: d.c2, d.ctid, d.*, t.* - Hash Cond: (d.c1 = t.c1) + Merge Cond: (d.c1 = t.c1) -> Foreign Scan on public.ft2 d Output: d.c2, d.ctid, d.*, d.c1 Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8, ctid FROM "S 1"."T 1" WHERE (("C 1" > 1000)) ORDER BY "C 1" ASC NULLS LAST FOR UPDATE - -> Hash + -> Materialize Output: t.*, t.c1 -> Foreign Scan on public.ft2 t Output: t.*, t.c1 - Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" + Remote SQL: SELECT "C 1", c2, c3, c4, c5, c6, c7, c8 FROM "S 1"."T 1" WHERE (("C 1" > 1000)) ORDER BY "C 1" ASC NULLS LAST (17 rows) UPDATE ft2 d SET c2 = CASE WHEN random() >= 0 THEN d.c2 ELSE 0 END diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c index 05f27f044b..b19462c758 100644 --- a/src/backend/nodes/outfuncs.c +++ b/src/backend/nodes/outfuncs.c @@ -2665,6 +2665,17 @@ _outEquivalenceMember(StringInfo str, const EquivalenceMember *node) WRITE_OID_FIELD(em_datatype); } +static void +_outEquivalenceFilter(StringInfo str, const EquivalenceFilter *node) +{ + WRITE_NODE_TYPE("EQUIVALENCEFILTER"); + + WRITE_NODE_FIELD(ef_const); + WRITE_OID_FIELD(ef_opno); + WRITE_BOOL_FIELD(ef_const_is_left); + WRITE_UINT_FIELD(ef_source_rel); +} + static void _outPathKey(StringInfo str, const PathKey *node) { @@ -4496,6 +4507,9 @@ outNode(StringInfo str, const void *obj) case T_EquivalenceMember: _outEquivalenceMember(str, obj); break; + case T_EquivalenceFilter: + _outEquivalenceFilter(str, obj); + break; case T_PathKey: _outPathKey(str, obj); break; diff --git a/src/backend/optimizer/path/equivclass.c b/src/backend/optimizer/path/equivclass.c index 60c0e3f108..89c7f0dc39 100644 --- a/src/backend/optimizer/path/equivclass.c +++ b/src/backend/optimizer/path/equivclass.c @@ -19,6 +19,7 @@ #include #include "access/stratnum.h" +#include "catalog/pg_am.h" #include "catalog/pg_type.h" #include "nodes/makefuncs.h" #include "nodes/nodeFuncs.h" @@ -1232,6 +1233,37 @@ generate_base_implied_equalities_const(PlannerInfo *root, } } +/* + * finds the opfamily and strategy number for the specified 'opno' and 'method' + * access method. Returns True if one is found and sets 'family' and + * 'amstrategy', or returns False if none are found. + */ +static bool +find_am_family_and_stategy(Oid opno, Oid method, Oid *family, int *amstrategy) +{ + List *opfamilies; + ListCell *l; + int strategy; + + opfamilies = get_opfamilies(opno, method); + + foreach(l, opfamilies) + { + Oid opfamily = lfirst_oid(l); + + strategy = get_op_opfamily_strategy(opno, opfamily); + + if (strategy) + { + *amstrategy = strategy; + *family = opfamily; + return true; + } + } + + return false; +} + /* * generate_base_implied_equalities when EC contains no pseudoconstants */ @@ -1241,6 +1273,7 @@ generate_base_implied_equalities_no_const(PlannerInfo *root, { EquivalenceMember **prev_ems; ListCell *lc; + ListCell *lc2; /* * We scan the EC members once and track the last-seen member for each @@ -1302,6 +1335,57 @@ generate_base_implied_equalities_no_const(PlannerInfo *root, rinfo->right_em = cur_em; } } + + /* + * Also push any EquivalenceFilter clauses down into all relations + * other than the one which the filter actually originated from. + */ + foreach(lc2, ec->ec_filters) + { + EquivalenceFilter *ef = (EquivalenceFilter *) lfirst(lc2); + Expr *leftexpr; + Expr *rightexpr; + int strategy; + Oid opno; + Oid family; + + if (ef->ef_source_rel == relid) + continue; + + if (!find_am_family_and_stategy(ef->ef_opno, BTREE_AM_OID, + &family, &strategy)) + continue; + + if (ef->ef_const_is_left) + { + leftexpr = (Expr *) ef->ef_const; + rightexpr = cur_em->em_expr; + } + else + { + leftexpr = cur_em->em_expr; + rightexpr = (Expr *) ef->ef_const; + } + + opno = get_opfamily_member(family, + exprType((Node *) leftexpr), + exprType((Node *) rightexpr), + strategy); + + if (opno == InvalidOid) + continue; + + process_implied_equality(root, opno, + ec->ec_collation, + leftexpr, + rightexpr, + bms_copy(ec->ec_relids), + bms_copy(cur_em->em_nullable_relids), + ec->ec_min_security, + ec->ec_below_outer_join, + false); + } + prev_ems[relid] = cur_em; } @@ -1883,6 +1967,104 @@ create_join_clause(PlannerInfo *root, return rinfo; } +/* + * distribute_filter_quals_to_eclass + * For each OpExpr in quallist look for an eclass which has an Expr + * matching the Expr in the OpExpr. If a match is found we add a new + * EquivalenceFilter to the eclass containing the filter details. + */ +void +distribute_filter_quals_to_eclass(PlannerInfo *root, List *quallist) +{ + ListCell *l; + + /* fast path for when no eclasses have been generated */ + if (root->eq_classes == NIL) + return; + + /* + * For each qual in quallist try and find an eclass which contains the + * non-Const part of the OpExpr. We'll tag any matches that we find onto + * the correct eclass. + */ + foreach(l, quallist) + { + OpExpr *opexpr = (OpExpr *) lfirst(l); + Expr *leftexpr = (Expr *) linitial(opexpr->args); + Expr *rightexpr = (Expr *) lsecond(opexpr->args); + Const *constexpr; + Expr *varexpr; + Relids exprrels; + int relid; + bool const_isleft; + ListCell *l2; + + /* + * Determine if the the OpExpr is in the form "expr op const" or + * "const op expr". + */ + if (IsA(leftexpr, Const)) + { + constexpr = (Const *) leftexpr; + varexpr = rightexpr; + const_isleft = true; + } + else + { + constexpr = (Const *) rightexpr; + varexpr = leftexpr; + const_isleft = false; + } + + exprrels = pull_varnos(root, (Node *) varexpr); + + /* should be filtered out, but we need to determine relid anyway */ + if (!bms_get_singleton_member(exprrels, &relid)) + continue; + + /* search for a matching eclass member in all eclasses */ + foreach(l2, root->eq_classes) + { + EquivalenceClass *ec = (EquivalenceClass *) lfirst(l2); + ListCell *l3; + + if (ec->ec_broken || ec->ec_has_volatile) + continue; + + /* + * if the eclass has a const then that const will serve as the + * filter, we needn't add any others. + */ + if (ec->ec_has_const) + continue; + + /* skip this eclass no members exist which belong to this relid */ + if (!bms_is_member(relid, ec->ec_relids)) + continue; + + foreach(l3, ec->ec_members) + { + EquivalenceMember *em = (EquivalenceMember *) lfirst(l3); + + if (!bms_is_member(relid, em->em_relids)) + continue; + + if (equal(em->em_expr, varexpr)) + { + EquivalenceFilter *efilter; + efilter = makeNode(EquivalenceFilter); + efilter->ef_const = (Const *) copyObject(constexpr); + efilter->ef_const_is_left = const_isleft; + efilter->ef_opno = opexpr->opno; + efilter->ef_source_rel = relid; + + ec->ec_filters = lappend(ec->ec_filters, efilter); + break; /* Onto the next eclass */ + } + } + } + } +} /* * reconsider_outer_join_clauses diff --git a/src/backend/optimizer/plan/initsplan.c b/src/backend/optimizer/plan/initsplan.c index fa2bfbfb72..f86276b667 100644 --- a/src/backend/optimizer/plan/initsplan.c +++ b/src/backend/optimizer/plan/initsplan.c @@ -53,7 +53,7 @@ static void extract_lateral_references(PlannerInfo *root, RelOptInfo *brel, static List *deconstruct_recurse(PlannerInfo *root, Node *jtnode, bool below_outer_join, Relids *qualscope, Relids *inner_join_rels, - List **postponed_qual_list); + List **postponed_qual_list, List **filter_qual_list); static void process_security_barrier_quals(PlannerInfo *root, int rti, Relids qualscope, bool below_outer_join); @@ -70,7 +70,8 @@ static void distribute_qual_to_rels(PlannerInfo *root, Node *clause, Relids qualscope, Relids ojscope, Relids outerjoin_nonnullable, - List **postponed_qual_list); + List **postponed_qual_list, + List **filter_qual_list); static bool check_outerjoin_delay(PlannerInfo *root, Relids *relids_p, Relids *nullable_relids_p, bool is_pushed_down); static bool check_equivalence_delay(PlannerInfo *root, @@ -650,6 +651,43 @@ create_lateral_join_info(PlannerInfo *root) } } +/* + * is_simple_filter_qual + * Analyzes an OpExpr to determine if it may be useful as an + * EquivalenceFilter. Returns true if the OpExpr may be of some use, or + * false if it should not be used. + */ +static bool +is_simple_filter_qual(PlannerInfo *root, OpExpr *expr) +{ + Expr *leftexpr; + Expr *rightexpr; + + if (!IsA(expr, OpExpr)) + return false; + + if (list_length(expr->args) != 2) + return false; + + leftexpr = (Expr *) linitial(expr->args); + rightexpr = (Expr *) lsecond(expr->args); + + /* XXX should we restrict these to simple Var op Const expressions? */ + if (IsA(leftexpr, Const)) + { + if (bms_membership(pull_varnos(root, (Node *) rightexpr)) == BMS_SINGLETON && + !contain_volatile_functions((Node *) rightexpr)) + return true; + } + else if (IsA(rightexpr, Const)) + { + if (bms_membership(pull_varnos(root, (Node *) leftexpr)) == BMS_SINGLETON && + !contain_volatile_functions((Node *) leftexpr)) + return true; + } + + return false; +} /***************************************************************************** * @@ -690,6 +728,7 @@ deconstruct_jointree(PlannerInfo *root) Relids qualscope; Relids inner_join_rels; List *postponed_qual_list = NIL; + List *filter_qual_list = NIL; /* Start recursion at top of jointree */ Assert(root->parse->jointree != NULL && @@ -700,11 +739,14 @@ deconstruct_jointree(PlannerInfo *root) result = deconstruct_recurse(root, (Node *) root->parse->jointree, false, &qualscope, &inner_join_rels, - &postponed_qual_list); + &postponed_qual_list, &filter_qual_list); /* Shouldn't be any leftover quals */ Assert(postponed_qual_list == NIL); + /* try and match each filter_qual_list item up with an eclass. */ + distribute_filter_quals_to_eclass(root, filter_qual_list); + return result; } @@ -725,6 +767,8 @@ deconstruct_jointree(PlannerInfo *root) * or free this, either) * *postponed_qual_list is a list of PostponedQual structs, which we can * add quals to if they turn out to belong to a higher join level + * *filter_qual_list is appended to with a list of quals which may be useful + * include as EquivalenceFilters. * Return value is the appropriate joinlist for this jointree node * * In addition, entries will be added to root->join_info_list for outer joins. @@ -732,7 +776,7 @@ deconstruct_jointree(PlannerInfo *root) static List * deconstruct_recurse(PlannerInfo *root, Node *jtnode, bool below_outer_join, Relids *qualscope, Relids *inner_join_rels, - List **postponed_qual_list) + List **postponed_qual_list, List **filter_qual_list) { List *joinlist; @@ -785,7 +829,8 @@ deconstruct_recurse(PlannerInfo *root, Node *jtnode, bool below_outer_join, below_outer_join, &sub_qualscope, inner_join_rels, - &child_postponed_quals); + &child_postponed_quals, + filter_qual_list); *qualscope = bms_add_members(*qualscope, sub_qualscope); sub_members = list_length(sub_joinlist); remaining--; @@ -819,7 +864,8 @@ deconstruct_recurse(PlannerInfo *root, Node *jtnode, bool below_outer_join, below_outer_join, JOIN_INNER, root->qual_security_level, *qualscope, NULL, NULL, - NULL); + NULL, + filter_qual_list); else *postponed_qual_list = lappend(*postponed_qual_list, pq); } @@ -835,7 +881,8 @@ deconstruct_recurse(PlannerInfo *root, Node *jtnode, bool below_outer_join, below_outer_join, JOIN_INNER, root->qual_security_level, *qualscope, NULL, NULL, - postponed_qual_list); + postponed_qual_list, + filter_qual_list); } } else if (IsA(jtnode, JoinExpr)) @@ -873,11 +920,13 @@ deconstruct_recurse(PlannerInfo *root, Node *jtnode, bool below_outer_join, leftjoinlist = deconstruct_recurse(root, j->larg, below_outer_join, &leftids, &left_inners, - &child_postponed_quals); + &child_postponed_quals, + filter_qual_list); rightjoinlist = deconstruct_recurse(root, j->rarg, below_outer_join, &rightids, &right_inners, - &child_postponed_quals); + &child_postponed_quals, + filter_qual_list); *qualscope = bms_union(leftids, rightids); *inner_join_rels = *qualscope; /* Inner join adds no restrictions for quals */ @@ -890,11 +939,13 @@ deconstruct_recurse(PlannerInfo *root, Node *jtnode, bool below_outer_join, leftjoinlist = deconstruct_recurse(root, j->larg, below_outer_join, &leftids, &left_inners, - &child_postponed_quals); + &child_postponed_quals, + filter_qual_list); rightjoinlist = deconstruct_recurse(root, j->rarg, true, &rightids, &right_inners, - &child_postponed_quals); + &child_postponed_quals, + filter_qual_list); *qualscope = bms_union(leftids, rightids); *inner_join_rels = bms_union(left_inners, right_inners); nonnullable_rels = leftids; @@ -904,11 +955,13 @@ deconstruct_recurse(PlannerInfo *root, Node *jtnode, bool below_outer_join, leftjoinlist = deconstruct_recurse(root, j->larg, below_outer_join, &leftids, &left_inners, - &child_postponed_quals); + &child_postponed_quals, + filter_qual_list); rightjoinlist = deconstruct_recurse(root, j->rarg, below_outer_join, &rightids, &right_inners, - &child_postponed_quals); + &child_postponed_quals, + filter_qual_list); *qualscope = bms_union(leftids, rightids); *inner_join_rels = bms_union(left_inners, right_inners); /* Semi join adds no restrictions for quals */ @@ -925,11 +978,13 @@ deconstruct_recurse(PlannerInfo *root, Node *jtnode, bool below_outer_join, leftjoinlist = deconstruct_recurse(root, j->larg, true, &leftids, &left_inners, - &child_postponed_quals); + &child_postponed_quals, + filter_qual_list); rightjoinlist = deconstruct_recurse(root, j->rarg, true, &rightids, &right_inners, - &child_postponed_quals); + &child_postponed_quals, + filter_qual_list); *qualscope = bms_union(leftids, rightids); *inner_join_rels = bms_union(left_inners, right_inners); /* each side is both outer and inner */ @@ -1013,7 +1068,8 @@ deconstruct_recurse(PlannerInfo *root, Node *jtnode, bool below_outer_join, root->qual_security_level, *qualscope, ojscope, nonnullable_rels, - postponed_qual_list); + postponed_qual_list, + filter_qual_list); } /* Now we can add the SpecialJoinInfo to join_info_list */ @@ -1117,6 +1173,7 @@ process_security_barrier_quals(PlannerInfo *root, qualscope, qualscope, NULL, + NULL, NULL); } security_level++; @@ -1610,7 +1667,8 @@ distribute_qual_to_rels(PlannerInfo *root, Node *clause, Relids qualscope, Relids ojscope, Relids outerjoin_nonnullable, - List **postponed_qual_list) + List **postponed_qual_list, + List **filter_qual_list) { Relids relids; bool is_pushed_down; @@ -1967,6 +2025,10 @@ distribute_qual_to_rels(PlannerInfo *root, Node *clause, /* No EC special case applies, so push it into the clause lists */ distribute_restrictinfo_to_rels(root, restrictinfo); + + /* Check if the qual looks useful to harvest as an EquivalenceFilter */ + if (filter_qual_list != NULL && is_simple_filter_qual(root, (OpExpr *) clause)) + *filter_qual_list = lappend(*filter_qual_list, clause); } /* diff --git a/src/backend/utils/cache/lsyscache.c b/src/backend/utils/cache/lsyscache.c index 91cd813ce8..b0243925e4 100644 --- a/src/backend/utils/cache/lsyscache.c +++ b/src/backend/utils/cache/lsyscache.c @@ -341,6 +341,34 @@ get_ordering_op_for_equality_op(Oid opno, bool use_lhs_type) return result; } +/* + * get_opfamilies + * Returns a list of Oids of each opfamily which 'opno' belonging to + * 'method' access method. + */ +List * +get_opfamilies(Oid opno, Oid method) +{ + List *result = NIL; + CatCList *catlist; + int i; + + catlist = SearchSysCacheList1(AMOPOPID, ObjectIdGetDatum(opno)); + + for (i = 0; i < catlist->n_members; i++) + { + HeapTuple tuple = &catlist->members[i]->tuple; + Form_pg_amop aform = (Form_pg_amop) GETSTRUCT(tuple); + + if (aform->amopmethod == method) + result = lappend_oid(result, aform->amopfamily); + } + + ReleaseSysCacheList(catlist); + + return result; +} + /* * get_mergejoin_opfamilies * Given a putatively mergejoinable operator, return a list of the OIDs diff --git a/src/include/nodes/nodes.h b/src/include/nodes/nodes.h index 7ce1fc4deb..ba879ab3e9 100644 --- a/src/include/nodes/nodes.h +++ b/src/include/nodes/nodes.h @@ -277,6 +277,7 @@ typedef enum NodeTag T_LimitPath, /* these aren't subclasses of Path: */ T_EquivalenceClass, + T_EquivalenceFilter, T_EquivalenceMember, T_PathKey, T_PathKeyInfo, diff --git a/src/include/nodes/pathnodes.h b/src/include/nodes/pathnodes.h index f407f1852d..f80b47ae2c 100644 --- a/src/include/nodes/pathnodes.h +++ b/src/include/nodes/pathnodes.h @@ -1132,6 +1132,7 @@ typedef struct EquivalenceClass List *ec_members; /* list of EquivalenceMembers */ List *ec_sources; /* list of generating RestrictInfos */ List *ec_derives; /* list of derived RestrictInfos */ + List *ec_filters; Relids ec_relids; /* all relids appearing in ec_members, except * for child members (see below) */ bool ec_has_const; /* any pseudoconstants in ec_members? */ @@ -1144,6 +1145,42 @@ typedef struct EquivalenceClass struct EquivalenceClass *ec_merged; /* set if merged into another EC */ } EquivalenceClass; +/* + * EquivalenceFilter - List of filters on Consts which belong to the + * EquivalenceClass. + * + * When building the equivalence classes we also collected a list of quals in + * the form of; "Expr op Const" and "Const op Expr". These are collected in the + * hope that we'll later generate an equivalence class which contains the + * "Expr" part. For example, if we parse a query such as; + * + * SELECT * FROM t1 INNER JOIN t2 ON t1.id = t2.id WHERE t1.id < 10; + * + * then since we'll end up with an equivalence class containing {t1.id,t2.id}, + * we'll tag the "< 10" filter onto the eclass. We are able to do this because + * the eclass proves equality between each class member, therefore all members + * must be below 10. + * + * EquivalenceFilters store the details required to allow us to push these + * filter clauses down into other relations which share an equivalence class + * containing a member which matches the expression of this EquivalenceFilter. + * + * ef_const is the Const value which this filter should filter against. + * ef_opno is the operator to filter on. + * ef_const_is_left marks if the OpExpr was in the form "Const op Expr" or + * "Expr op Const". + * ef_source_rel is the relation id of where this qual originated from. + */ +typedef struct EquivalenceFilter +{ + NodeTag type; + + Const *ef_const; /* the constant expression to filter on */ + Oid ef_opno; /* Operator Oid of filter operator */ + bool ef_const_is_left; /* Is the Const on the left of the OpExrp? */ + Index ef_source_rel; /* relid of originating relation. */ +} EquivalenceFilter; + /* * If an EC contains a const and isn't below-outer-join, any PathKey depending * on it must be redundant, since there's only one possible value of the key. diff --git a/src/include/optimizer/paths.h b/src/include/optimizer/paths.h index b6e137cf83..79553778cd 100644 --- a/src/include/optimizer/paths.h +++ b/src/include/optimizer/paths.h @@ -127,6 +127,7 @@ extern bool process_equivalence(PlannerInfo *root, extern Expr *canonicalize_ec_expression(Expr *expr, Oid req_type, Oid req_collation); extern void reconsider_outer_join_clauses(PlannerInfo *root); +extern void distribute_filter_quals_to_eclass(PlannerInfo *root, List *quallist); extern EquivalenceClass *get_eclass_for_sort_expr(PlannerInfo *root, Expr *expr, Relids nullable_relids, diff --git a/src/include/utils/lsyscache.h b/src/include/utils/lsyscache.h index 5b5fac0397..e0ed28f330 100644 --- a/src/include/utils/lsyscache.h +++ b/src/include/utils/lsyscache.h @@ -78,6 +78,7 @@ extern bool get_ordering_op_properties(Oid opno, Oid *opfamily, Oid *opcintype, int16 *strategy); extern Oid get_equality_op_for_ordering_op(Oid opno, bool *reverse); extern Oid get_ordering_op_for_equality_op(Oid opno, bool use_lhs_type); +extern List *get_opfamilies(Oid opno, Oid method); extern List *get_mergejoin_opfamilies(Oid opno); extern void get_btree_opfamilies(Oid opno, List **mergeable_opfamilies, List **unmergeable_btree_opfamilies); extern bool get_compatible_hash_operators(Oid opno, diff --git a/src/test/regress/expected/equivclass.out b/src/test/regress/expected/equivclass.out index 126f7047fe..92fcec1158 100644 --- a/src/test/regress/expected/equivclass.out +++ b/src/test/regress/expected/equivclass.out @@ -407,14 +407,14 @@ set session authorization regress_user_ectest; explain (costs off) select * from ec0 a, ec1 b where a.ff = b.ff and a.ff = 43::bigint::int8alias1; - QUERY PLAN ---------------------------------------------- + QUERY PLAN +---------------------------------------------------------------------- Nested Loop -> Index Scan using ec0_pkey on ec0 a Index Cond: (ff = '43'::int8alias1) -> Index Scan using ec1_pkey on ec1 b Index Cond: (ff = a.ff) - Filter: (f1 < '5'::int8alias1) + Filter: ((f1 < '5'::int8alias1) AND (ff = '43'::int8alias1)) (6 rows) reset session authorization; @@ -451,3 +451,42 @@ explain (costs off) -- this should not require a sort Filter: (f1 = 'foo'::name) (2 rows) +-- test equivalence filters +explain (costs off) + select * from ec0 + inner join ec1 on ec0.ff = ec1.ff + where ec0.ff between 1 and 10; + QUERY PLAN +------------------------------------------------------------ + Nested Loop + Join Filter: (ec0.ff = ec1.ff) + -> Bitmap Heap Scan on ec0 + Recheck Cond: ((ff >= 1) AND (ff <= 10)) + -> Bitmap Index Scan on ec0_pkey + Index Cond: ((ff >= 1) AND (ff <= 10)) + -> Materialize + -> Bitmap Heap Scan on ec1 + Recheck Cond: ((ff >= 1) AND (ff <= 10)) + -> Bitmap Index Scan on ec1_pkey + Index Cond: ((ff >= 1) AND (ff <= 10)) +(11 rows) + +explain (costs off) + select * from ec0 + inner join ec1 on ec0.ff = ec1.ff + where ec1.ff between 1 and 10; + QUERY PLAN +------------------------------------------------------------ + Nested Loop + Join Filter: (ec0.ff = ec1.ff) + -> Bitmap Heap Scan on ec0 + Recheck Cond: ((ff >= 1) AND (ff <= 10)) + -> Bitmap Index Scan on ec0_pkey + Index Cond: ((ff >= 1) AND (ff <= 10)) + -> Materialize + -> Bitmap Heap Scan on ec1 + Recheck Cond: ((ff >= 1) AND (ff <= 10)) + -> Bitmap Index Scan on ec1_pkey + Index Cond: ((ff >= 1) AND (ff <= 10)) +(11 rows) + diff --git a/src/test/regress/expected/join.out b/src/test/regress/expected/join.out index 2538bd6a79..f173074621 100644 --- a/src/test/regress/expected/join.out +++ b/src/test/regress/expected/join.out @@ -3337,7 +3337,7 @@ where t1.unique2 < 42 and t1.stringu1 > t2.stringu2; Join Filter: (t1.stringu1 > t2.stringu2) -> Nested Loop -> Seq Scan on int4_tbl i1 - Filter: (f1 = 0) + Filter: ((f1 = 0) AND (11 < 42)) -> Index Scan using tenk1_unique2 on tenk1 t1 Index Cond: ((unique2 = (11)) AND (unique2 < 42)) -> Index Scan using tenk1_unique1 on tenk1 t2 @@ -6544,23 +6544,22 @@ where exists (select 1 from tenk1 t3 --------------------------------------------------------------------------------- Nested Loop Output: t1.unique1, t2.hundred - -> Hash Join + -> Nested Loop Output: t1.unique1, t3.tenthous - Hash Cond: (t3.thousand = t1.unique1) + Join Filter: (t1.unique1 = t3.thousand) + -> Index Only Scan using onek_unique1 on public.onek t1 + Output: t1.unique1 + Index Cond: (t1.unique1 < 1) -> HashAggregate Output: t3.thousand, t3.tenthous Group Key: t3.thousand, t3.tenthous -> Index Only Scan using tenk1_thous_tenthous on public.tenk1 t3 Output: t3.thousand, t3.tenthous - -> Hash - Output: t1.unique1 - -> Index Only Scan using onek_unique1 on public.onek t1 - Output: t1.unique1 - Index Cond: (t1.unique1 < 1) + Index Cond: (t3.thousand < 1) -> Index Only Scan using tenk1_hundred on public.tenk1 t2 Output: t2.hundred Index Cond: (t2.hundred = t3.tenthous) -(18 rows) +(17 rows) -- ... unless it actually is unique create table j3 as select unique1, tenthous from onek; @@ -6578,15 +6577,16 @@ where exists (select 1 from j3 Output: t1.unique1, t2.hundred -> Nested Loop Output: t1.unique1, j3.tenthous + Join Filter: (t1.unique1 = j3.unique1) -> Index Only Scan using onek_unique1 on public.onek t1 Output: t1.unique1 Index Cond: (t1.unique1 < 1) -> Index Only Scan using j3_unique1_tenthous_idx on public.j3 Output: j3.unique1, j3.tenthous - Index Cond: (j3.unique1 = t1.unique1) + Index Cond: (j3.unique1 < 1) -> Index Only Scan using tenk1_hundred on public.tenk1 t2 Output: t2.hundred Index Cond: (t2.hundred = j3.tenthous) -(13 rows) +(14 rows) drop table j3; diff --git a/src/test/regress/expected/merge.out b/src/test/regress/expected/merge.out index af670e28e7..ab3a711d61 100644 --- a/src/test/regress/expected/merge.out +++ b/src/test/regress/expected/merge.out @@ -1437,17 +1437,17 @@ SELECT explain_merge(' MERGE INTO ex_mtarget t USING ex_msource s ON t.a = s.a AND t.a < -1000 WHEN MATCHED AND t.a < 10 THEN DO NOTHING'); - explain_merge --------------------------------------------------------------------- + explain_merge +-------------------------------------------------------------- Merge on ex_mtarget t (actual rows=0 loops=1) -> Hash Join (actual rows=0 loops=1) - Hash Cond: (s.a = t.a) - -> Seq Scan on ex_msource s (actual rows=1 loops=1) - -> Hash (actual rows=0 loops=1) - Buckets: xxx Batches: xxx Memory Usage: xxx - -> Seq Scan on ex_mtarget t (actual rows=0 loops=1) + Hash Cond: (t.a = s.a) + -> Seq Scan on ex_mtarget t (actual rows=0 loops=1) + Filter: (a < '-1000'::integer) + Rows Removed by Filter: 54 + -> Hash (never executed) + -> Seq Scan on ex_msource s (never executed) Filter: (a < '-1000'::integer) - Rows Removed by Filter: 54 (9 rows) DROP TABLE ex_msource, ex_mtarget; diff --git a/src/test/regress/expected/partition_join.out b/src/test/regress/expected/partition_join.out index 03926a8413..3be9a2bed5 100644 --- a/src/test/regress/expected/partition_join.out +++ b/src/test/regress/expected/partition_join.out @@ -186,17 +186,17 @@ SELECT t1.a, t1.c, t2.b, t2.c FROM (SELECT 50 phv, * FROM prt1 WHERE prt1.b = 0) -- Join with pruned partitions from joining relations EXPLAIN (COSTS OFF) SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.b = 0 ORDER BY t1.a, t2.b; - QUERY PLAN ------------------------------------------------------ + QUERY PLAN +------------------------------------------------------------------- Sort Sort Key: t1.a -> Hash Join Hash Cond: (t2.b = t1.a) -> Seq Scan on prt2_p2 t2 - Filter: (b > 250) + Filter: ((b > 250) AND (b < 450)) -> Hash -> Seq Scan on prt1_p2 t1 - Filter: ((a < 450) AND (b = 0)) + Filter: ((a < 450) AND (a > 250) AND (b = 0)) (9 rows) SELECT t1.a, t1.c, t2.b, t2.c FROM prt1 t1, prt2 t2 WHERE t1.a = t2.b AND t1.a < 450 AND t2.b > 250 AND t1.b = 0 ORDER BY t1.a, t2.b; @@ -3089,16 +3089,18 @@ SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_adv t1 INNER JOIN prt2_adv t2 ON (t1.a = -> Hash Join Hash Cond: (t2_1.b = t1_1.a) -> Seq Scan on prt2_adv_p1 t2_1 + Filter: (b < 300) -> Hash -> Seq Scan on prt1_adv_p1 t1_1 Filter: ((a < 300) AND (b = 0)) -> Hash Join Hash Cond: (t2_2.b = t1_2.a) -> Seq Scan on prt2_adv_p2 t2_2 + Filter: (b < 300) -> Hash -> Seq Scan on prt1_adv_p2 t1_2 Filter: ((a < 300) AND (b = 0)) -(15 rows) +(17 rows) SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_adv t1 INNER JOIN prt2_adv t2 ON (t1.a = t2.b) WHERE t1.a < 300 AND t1.b = 0 ORDER BY t1.a, t2.b; a | c | b | c @@ -3128,16 +3130,18 @@ SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_adv t1 INNER JOIN prt2_adv t2 ON (t1.a = -> Hash Join Hash Cond: (t2_1.b = t1_1.a) -> Seq Scan on prt2_adv_p1 t2_1 + Filter: ((b >= 100) AND (b < 300)) -> Hash -> Seq Scan on prt1_adv_p1 t1_1 Filter: ((a >= 100) AND (a < 300) AND (b = 0)) -> Hash Join Hash Cond: (t2_2.b = t1_2.a) -> Seq Scan on prt2_adv_p2 t2_2 + Filter: ((b >= 100) AND (b < 300)) -> Hash -> Seq Scan on prt1_adv_p2 t1_2 Filter: ((a >= 100) AND (a < 300) AND (b = 0)) -(15 rows) +(17 rows) SELECT t1.a, t1.c, t2.b, t2.c FROM prt1_adv t1 INNER JOIN prt2_adv t2 ON (t1.a = t2.b) WHERE t1.a >= 100 AND t1.a < 300 AND t1.b = 0 ORDER BY t1.a, t2.b; a | c | b | c @@ -4681,27 +4685,32 @@ SELECT t1.*, t2.* FROM alpha t1 INNER JOIN beta t2 ON (t1.a = t2.a AND t1.b = t2 Filter: ((b >= 125) AND (b < 225)) -> Hash -> Seq Scan on beta_neg_p1 t2_1 + Filter: ((b >= 125) AND (b < 225)) -> Hash Join - Hash Cond: ((t2_2.a = t1_2.a) AND (t2_2.b = t1_2.b)) - -> Seq Scan on beta_neg_p2 t2_2 + Hash Cond: ((t1_2.a = t2_2.a) AND (t1_2.b = t2_2.b)) + -> Seq Scan on alpha_neg_p2 t1_2 + Filter: ((b >= 125) AND (b < 225)) -> Hash - -> Seq Scan on alpha_neg_p2 t1_2 + -> Seq Scan on beta_neg_p2 t2_2 Filter: ((b >= 125) AND (b < 225)) -> Hash Join - Hash Cond: ((t2_4.a = t1_4.a) AND (t2_4.b = t1_4.b)) + Hash Cond: ((t1_4.a = t2_4.a) AND (t1_4.b = t2_4.b)) -> Append - -> Seq Scan on beta_pos_p1 t2_4 - -> Seq Scan on beta_pos_p2 t2_5 - -> Seq Scan on beta_pos_p3 t2_6 + -> Seq Scan on alpha_pos_p1 t1_4 + Filter: ((b >= 125) AND (b < 225)) + -> Seq Scan on alpha_pos_p2 t1_5 + Filter: ((b >= 125) AND (b < 225)) + -> Seq Scan on alpha_pos_p3 t1_6 + Filter: ((b >= 125) AND (b < 225)) -> Hash -> Append - -> Seq Scan on alpha_pos_p1 t1_4 + -> Seq Scan on beta_pos_p1 t2_4 Filter: ((b >= 125) AND (b < 225)) - -> Seq Scan on alpha_pos_p2 t1_5 + -> Seq Scan on beta_pos_p2 t2_5 Filter: ((b >= 125) AND (b < 225)) - -> Seq Scan on alpha_pos_p3 t1_6 + -> Seq Scan on beta_pos_p3 t2_6 Filter: ((b >= 125) AND (b < 225)) -(29 rows) +(34 rows) SELECT t1.*, t2.* FROM alpha t1 INNER JOIN beta t2 ON (t1.a = t2.a AND t1.b = t2.b) WHERE t1.b >= 125 AND t1.b < 225 ORDER BY t1.a, t1.b; a | b | c | a | b | c diff --git a/src/test/regress/sql/equivclass.sql b/src/test/regress/sql/equivclass.sql index 247b0a3105..dae83c4196 100644 --- a/src/test/regress/sql/equivclass.sql +++ b/src/test/regress/sql/equivclass.sql @@ -269,3 +269,15 @@ create temp view overview as select f1::information_schema.sql_identifier as sqli, f2 from undername; explain (costs off) -- this should not require a sort select * from overview where sqli = 'foo' order by sqli; + + +-- test equivalence filters +explain (costs off) + select * from ec0 + inner join ec1 on ec0.ff = ec1.ff + where ec0.ff between 1 and 10; + +explain (costs off) + select * from ec0 + inner join ec1 on ec0.ff = ec1.ff + where ec1.ff between 1 and 10; -- 2.37.0