From e5888750063ce306f420f23f53e2dcd13177f682 Mon Sep 17 00:00:00 2001 From: amit Date: Tue, 12 Dec 2017 16:17:10 +0900 Subject: [PATCH 5/5] Teach planner to use get_partitions_from_clauses() Current method of selecting a table's partitions to be scanned involves applying constraint exclusion against the partition constraint of each partition, which works by comparing a query's clauses against the partition constraint and exclude a partition if the clauses refute the latter. A dummy path is added for each partition that is excluded. This algorithm takes linear time with a big constant, especially given that we repeat the work of matching clauses to the partition constraint for every partition. Instead, we can match clauses only once by comparing them against the (parent) table's partition key using the information in its PartitionScheme. Further, if we pass the set of matched clauses to get_partitions_from_clauses(), we get the set of matching partitions in (hopefully) less time than determining the same by running the matching algorithm separately for each partition. Authors: Amit Langote, Dilip Kumar --- src/backend/optimizer/path/allpaths.c | 406 +++++++++++++++++++++++++- src/backend/optimizer/path/joinrels.c | 24 ++ src/backend/optimizer/util/plancat.c | 33 ++- src/include/nodes/relation.h | 7 +- src/test/regress/expected/inherit.out | 8 +- src/test/regress/expected/partition_prune.out | 340 +++++++++++++++++---- src/test/regress/sql/partition_prune.sql | 47 ++- 7 files changed, 786 insertions(+), 79 deletions(-) diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c index 83f79ea6cb..eeaf8fd935 100644 --- a/src/backend/optimizer/path/allpaths.c +++ b/src/backend/optimizer/path/allpaths.c @@ -20,8 +20,10 @@ #include "access/sysattr.h" #include "access/tsmapi.h" +#include "catalog/partition.h" #include "catalog/pg_class.h" #include "catalog/pg_operator.h" +#include "catalog/pg_opfamily.h" #include "catalog/pg_proc.h" #include "foreign/fdwapi.h" #include "miscadmin.h" @@ -136,6 +138,14 @@ static void recurse_push_qual(Node *setOp, Query *topquery, static void remove_unused_subquery_outputs(Query *subquery, RelOptInfo *rel); static void add_paths_to_append_rel(PlannerInfo *root, RelOptInfo *rel, List *live_childrels); +static List *get_append_rel_partitions(PlannerInfo *root, + RelOptInfo *rel, + RangeTblEntry *rte); +static List *match_clauses_to_partkey(PlannerInfo *root, + RelOptInfo *rel, + List *clauses, + bool *contains_const, + bool *constfalse); /* @@ -847,6 +857,397 @@ set_foreign_pathlist(PlannerInfo *root, RelOptInfo *rel, RangeTblEntry *rte) } /* + * get_append_rel_partitions + * Return the list of partitions of rel that pass the clauses mentioned + * in rel->baserestrictinfo. An empty list is returned if no matching + * partitions were found. + * + * Returned list contains the AppendRelInfos of chosen partitions. + */ +static List * +get_append_rel_partitions(PlannerInfo *root, + RelOptInfo *rel, + RangeTblEntry *rte) +{ + List *partclauses; + bool contains_const, + constfalse; + List *result = NIL; + int i; + Relation parent; + PartitionDesc partdesc; + Bitmapset *partindexes; + + /* + * Get the clauses that match the partition key, including information + * about any nullness tests against partition keys. Set keynullness to + * a invalid value of NullTestType, which 0 is not. + */ + partclauses = match_clauses_to_partkey(root, rel, + list_copy(rel->baserestrictinfo), + &contains_const, + &constfalse); + + /* We're done here. */ + if (constfalse) + return NIL; + + parent = heap_open(rte->relid, NoLock); + partdesc = RelationGetPartitionDesc(parent); + + /* + * If we have matched clauses that contain at least one constant operand, + * then use these to prune partitions. + */ + if (partclauses != NIL && contains_const) + partindexes = get_partitions_from_clauses(parent, rel->relid, + partclauses); + else + { + /* + * Else there are no clauses that are useful to prune any paritions, + * so we must scan all partitions. + */ + partindexes = bms_add_range(NULL, 0, partdesc->nparts - 1); + } + + /* Fetch the partition appinfos. */ + i = -1; + while ((i = bms_next_member(partindexes, i)) >= 0) + { + AppendRelInfo *appinfo = rel->part_appinfos[i]; + +#ifdef USE_ASSERT_CHECKING + RangeTblEntry *rte = planner_rt_fetch(appinfo->child_relid, root); + + /* + * Must be the intended child's RTE here, because appinfos are ordered + * the same way as partitions in the partition descriptor. + */ + Assert(partdesc->oids[i] == rte->relid); +#endif + result = lappend(result, appinfo); + } + + heap_close(parent, NoLock); + + return result; +} + +#define PartCollMatchesExprColl(partcoll, exprcoll) \ + ((partcoll) == InvalidOid || (partcoll) == (exprcoll)) + +/* + * match_clauses_to_partkey + * Match clauses with rel's partition key + * + * For an individual clause to match with a partition key column, the clause + * must be an operator clause of the form (partkey op const) or (const op + * partkey); the latter only if a suitable commutator exists. Furthermore, + * the operator must be strict and its input collation must match the partition + * collation. The aforementioned "const" means any expression that doesn't + * involve a volatile function or a Var of this relation. We allow Vars + * belonging to other relations (for example, if the clause is a join clause), + * but they are treated as parameters whose values are not known now, so cannot + * be used for partition pruning right within the planner. It's the + * responsibility of higher code levels to manage restriction and join clauses + * appropriately. + * + * If a NullTest against a partition key is encountered, it's added to the + * result as well. + * + * If clauses contains at least one constant operand or a Nullness test, + * *contains_const is set so that the caller can pass the clauses to the + * partitioning module right away. + * + * If the list contains a pseudo-constant RestrictInfo with constant false + * value, *constfalse is set. + */ +static List * +match_clauses_to_partkey(PlannerInfo *root, + RelOptInfo *rel, + List *clauses, + bool *contains_const, + bool *constfalse) +{ + PartitionScheme partscheme = rel->part_scheme; + List *result = NIL; + ListCell *lc; + + *contains_const = false; + *constfalse = false; + + Assert (partscheme != NULL); + + foreach(lc, clauses) + { + Node *member = lfirst(lc); + Expr *clause; + int i; + + if (IsA(member, RestrictInfo)) + { + RestrictInfo *rinfo = (RestrictInfo *) member; + + clause = rinfo->clause; + if (rinfo->pseudoconstant && + (IsA(clause, Const) && + ((((Const *) clause)->constisnull) || + !DatumGetBool(((Const *) clause)->constvalue)))) + { + *constfalse = true; + return NIL; + } + } + else + clause = (Expr *) member; + + /* + * For a BoolExpr, we should try to match each of its args with the + * partition key as described below for each type. + */ + if (IsA(clause, BoolExpr)) + { + if (or_clause((Node *) clause)) + { + /* + * For each of OR clause's args, call this function + * recursively with a given arg as the only member in the + * input list and see if it's returned as matching the + * partition key. Add the OR clause to the result iff at + * least one of its args contain a matching clause. + */ + BoolExpr *orclause = (BoolExpr *) clause; + ListCell *lc1; + bool arg_matches_key = false, + matched_arg_contains_const = false, + all_args_constfalse = true; + + foreach (lc1, orclause->args) + { + Node *arg = lfirst(lc1); + bool contains_const1, + constfalse1; + + if (match_clauses_to_partkey(root, rel, list_make1(arg), + &contains_const1, + &constfalse1) != NIL) + { + arg_matches_key = true; + matched_arg_contains_const = contains_const1; + } + + /* We got at least one arg that is not constant false. */ + if (!constfalse1) + all_args_constfalse = false; + } + + if (arg_matches_key) + { + result = lappend(result, clause); + *contains_const = matched_arg_contains_const; + } + + /* OR clause is "constant false" if all of its args are. */ + *constfalse = all_args_constfalse; + continue; + } + else if (and_clause((Node *) clause)) + { + /* + * Since the clause is itself implicitly ANDed with other + * clauses in the input list, queue the args to be processed + * later as if they were part of the original input list. + */ + clauses = list_concat(clauses, + list_copy(((BoolExpr *) clause)->args)); + continue; + } + + /* Fall-through for a NOT clause, which is handled below. */ + } + + for (i = 0; i < partscheme->partnatts; i++) + { + Node *partkey = linitial(rel->partexprs[i]); + Oid partopfamily = partscheme->partopfamily[i], + partcoll = partscheme->partcollation[i]; + + /* + * Check if the clauses matches the partition key and add it to + * the result list if other things such as operator input + * collation, strictness, etc. look fine. + */ + if (is_opclause(clause)) + { + Expr *constexpr, + *leftop, + *rightop; + Relids constrelids, + left_relids, + right_relids; + Oid expr_op, + expr_coll; + + leftop = (Expr *) get_leftop(clause); + rightop = (Expr *) get_rightop(clause); + expr_op = ((OpExpr *) clause)->opno; + expr_coll = ((OpExpr *) clause)->inputcollid; + left_relids = pull_varnos((Node *) leftop); + right_relids = pull_varnos((Node *) rightop); + + if (IsA(leftop, RelabelType)) + leftop = ((RelabelType *) leftop)->arg; + if (IsA(rightop, RelabelType)) + rightop = ((RelabelType *) rightop)->arg; + + if (equal(leftop, partkey)) + { + constexpr = rightop; + constrelids = right_relids; + } + else if (equal(rightop, partkey)) + { + constexpr = leftop; + constrelids = left_relids; + expr_op = get_commutator(expr_op); + + /* + * If no commutator exists, cannot flip the qual's args, + * so give up. + */ + if (!OidIsValid(expr_op)) + continue; + } + else + /* Neither argument matches the partition key. */ + continue; + + /* + * Useless if what we're thinking of as a constant is actually + * a Var coming from this relation. + */ + if (bms_is_member(rel->relid, constrelids)) + continue; + + /* + * Also, useless, if the clause's collation is different from + * the partitioning collation. + */ + if (!PartCollMatchesExprColl(partcoll, expr_coll)) + continue; + + /* + * Only allow strict operators to think sanely about the + * behavior with null arguments. + */ + if (!op_strict(expr_op)) + continue; + + /* Useless if the "constant" can change its value. */ + if (contain_volatile_functions((Node *) constexpr)) + continue; + + /* + * Everything seems to be fine, so add it to the list of + * clauses we will use for pruning. + */ + result = lappend(result, clause); + + if (!*contains_const) + *contains_const = IsA(constexpr, Const); + } + else if (IsA(clause, ScalarArrayOpExpr)) + { + ScalarArrayOpExpr *saop = (ScalarArrayOpExpr *) clause; + Oid saop_op = saop->opno; + Oid saop_coll = saop->inputcollid; + Node *leftop = (Node *) linitial(saop->args), + *rightop = (Node *) lsecond(saop->args); + + if (IsA(leftop, RelabelType)) + leftop = (Node *) ((RelabelType *) leftop)->arg; + if (!equal(leftop, partkey)) + continue; + + /* Check if saop_op is compatible with partitioning. */ + if (!op_strict(saop_op)) + continue; + + /* Useless if the "constant" can change its value. */ + if (contain_volatile_functions((Node *) rightop)) + continue; + + /* + * Also, useless, if the clause's collation is different from + * the partitioning collation. + */ + if (!PartCollMatchesExprColl(partcoll, saop_coll)) + continue; + + /* OK to add to the result. */ + result = lappend(result, clause); + if (IsA(estimate_expression_value(root, rightop), Const)) + *contains_const = true; + else + *contains_const = false; + } + else if (IsA(clause, NullTest)) + { + NullTest *nulltest = (NullTest *) clause; + Node *arg = (Node *) nulltest->arg; + + if (equal(arg, partkey)) + { + result = lappend(result, nulltest); + /* A Nullness test can be used right away. */ + *contains_const = true; + } + } + /* + * Certain Boolean conditions have a special shape, which we + * accept if the partitioning opfamily accepts Boolean conditions. + */ + else if (IsBooleanOpfamily(partopfamily) && + (IsA(clause, BooleanTest) || + IsA(clause, Var) || not_clause((Node *) clause))) + { + /* + * Only accept those for pruning that appear to be + * IS [NOT] TRUE/FALSE. + */ + if (IsA(clause, BooleanTest)) + { + BooleanTest *btest = (BooleanTest *) clause; + Expr *arg = btest->arg; + + if (btest->booltesttype != IS_UNKNOWN && + btest->booltesttype != IS_NOT_UNKNOWN && + equal((Node *) arg, partkey)) + result = lappend(result, clause); + } + else if (IsA(clause, Var)) + { + if (equal((Node *) clause, partkey)) + result = lappend(result, clause); + } + else + { + Node *arg = (Node *) get_notclausearg((Expr *) clause); + + if (equal(arg, partkey)) + result = lappend(result, clause); + } + + *contains_const = true; + } + } + } + + return result; +} + +/* * set_append_rel_size * Set size estimates for a simple "append relation" * @@ -888,10 +1289,7 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel, } else { - int i; - - for (i = 0; i < rel->nparts; i++) - rel_appinfos = lappend(rel_appinfos, rel->part_appinfos[i]); + rel_appinfos = get_append_rel_partitions(root, rel, rte); rel->live_partitioned_rels = list_make1_int(rti); } diff --git a/src/backend/optimizer/path/joinrels.c b/src/backend/optimizer/path/joinrels.c index 5e03f8bc21..5bd30312cb 100644 --- a/src/backend/optimizer/path/joinrels.c +++ b/src/backend/optimizer/path/joinrels.c @@ -1397,6 +1397,30 @@ try_partition_wise_join(PlannerInfo *root, RelOptInfo *rel1, RelOptInfo *rel2, child_rel2->relids); /* + * If either child_rel1 or child_rel2 is not a live partition, they'd + * not have been touched by set_append_rel_size. So, its RelOptInfo + * would be missing some information that set_append_rel_size sets for + * live partitions, such as the target list, child EQ members, etc. + * We need to make the RelOptInfo of even the dead partitions look + * minimally valid and as having a valid dummy path attached to it. + */ + if (IS_SIMPLE_REL(child_rel1) && child_rel1->pathlist == NIL) + { + AppendRelInfo *appinfo = rel1->part_appinfos[cnt_parts]; + + set_basic_child_rel_properties(root, rel1, child_rel1, appinfo); + mark_dummy_rel(child_rel1); + } + + if (IS_SIMPLE_REL(child_rel2) && child_rel2->pathlist == NIL) + { + AppendRelInfo *appinfo = rel2->part_appinfos[cnt_parts]; + + set_basic_child_rel_properties(root, rel2, child_rel2, appinfo); + mark_dummy_rel(child_rel2); + } + + /* * Construct restrictions applicable to the child join from those * applicable to the parent join. */ diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c index f7438714c4..df963f701f 100644 --- a/src/backend/optimizer/util/plancat.c +++ b/src/backend/optimizer/util/plancat.c @@ -1161,7 +1161,6 @@ get_relation_constraints(PlannerInfo *root, Index varno = rel->relid; Relation relation; TupleConstr *constr; - List *pcqual; /* * We assume the relation has already been safely locked. @@ -1248,21 +1247,25 @@ get_relation_constraints(PlannerInfo *root, } /* Append partition predicates, if any */ - pcqual = RelationGetPartitionQual(relation); - if (pcqual) + if (root->parse->commandType != CMD_SELECT) { - /* - * Run each expression through const-simplification and - * canonicalization similar to check constraints. - */ - pcqual = (List *) eval_const_expressions(root, (Node *) pcqual); - pcqual = (List *) canonicalize_qual((Expr *) pcqual); + List *pcqual = RelationGetPartitionQual(relation); + + if (pcqual) + { + /* + * Run each expression through const-simplification and + * canonicalization similar to check constraints. + */ + pcqual = (List *) eval_const_expressions(root, (Node *) pcqual); + pcqual = (List *) canonicalize_qual((Expr *) pcqual); - /* Fix Vars to have the desired varno */ - if (varno != 1) - ChangeVarNodes((Node *) pcqual, 1, varno, 0); + /* Fix Vars to have the desired varno */ + if (varno != 1) + ChangeVarNodes((Node *) pcqual, 1, varno, 0); - result = list_concat(result, pcqual); + result = list_concat(result, pcqual); + } } heap_close(relation, NoLock); @@ -1920,6 +1923,10 @@ find_partition_scheme(PlannerInfo *root, Relation relation) memcpy(part_scheme->parttypcoll, partkey->parttypcoll, sizeof(Oid) * partnatts); + part_scheme->partcollation = (Oid *) palloc(sizeof(Oid) * partnatts); + memcpy(part_scheme->partcollation, partkey->partcollation, + sizeof(Oid) * partnatts); + part_scheme->parttyplen = (int16 *) palloc(sizeof(int16) * partnatts); memcpy(part_scheme->parttyplen, partkey->parttyplen, sizeof(int16) * partnatts); diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h index c445f401d9..bcb669d212 100644 --- a/src/include/nodes/relation.h +++ b/src/include/nodes/relation.h @@ -342,6 +342,10 @@ typedef struct PlannerInfo * partition bounds. Since partition key data types and the opclass declared * input data types are expected to be binary compatible (per ResolveOpClass), * both of those should have same byval and length properties. + * + * Since partitioning might be using a collation for a given partition key + * column that is not same as the collation implied by column's type, store + * the same separately. */ typedef struct PartitionSchemeData { @@ -349,7 +353,8 @@ typedef struct PartitionSchemeData int16 partnatts; /* number of partition attributes */ Oid *partopfamily; /* OIDs of operator families */ Oid *partopcintype; /* OIDs of opclass declared input data types */ - Oid *parttypcoll; /* OIDs of collations of partition keys. */ + Oid *parttypcoll; /* OIDs of partition key type collation. */ + Oid *partcollation; /* OIDs of partitioning collation */ /* Cached information about partition key data types. */ int16 *parttyplen; diff --git a/src/test/regress/expected/inherit.out b/src/test/regress/expected/inherit.out index a79f891da7..2072766efd 100644 --- a/src/test/regress/expected/inherit.out +++ b/src/test/regress/expected/inherit.out @@ -1715,11 +1715,9 @@ explain (costs off) select * from list_parted where a = 'ab' or a in (null, 'cd' Append -> Seq Scan on part_ab_cd Filter: (((a)::text = 'ab'::text) OR ((a)::text = ANY ('{NULL,cd}'::text[]))) - -> Seq Scan on part_ef_gh - Filter: (((a)::text = 'ab'::text) OR ((a)::text = ANY ('{NULL,cd}'::text[]))) -> Seq Scan on part_null_xy Filter: (((a)::text = 'ab'::text) OR ((a)::text = ANY ('{NULL,cd}'::text[]))) -(7 rows) +(5 rows) explain (costs off) select * from list_parted where a = 'ab'; QUERY PLAN @@ -1906,11 +1904,13 @@ explain (costs off) select * from mcrparted where abs(b) = 5; -- scans all parti Filter: (abs(b) = 5) -> Seq Scan on mcrparted3 Filter: (abs(b) = 5) + -> Seq Scan on mcrparted4 + Filter: (abs(b) = 5) -> Seq Scan on mcrparted5 Filter: (abs(b) = 5) -> Seq Scan on mcrparted_def Filter: (abs(b) = 5) -(13 rows) +(15 rows) explain (costs off) select * from mcrparted where a > -1; -- scans all partitions QUERY PLAN diff --git a/src/test/regress/expected/partition_prune.out b/src/test/regress/expected/partition_prune.out index aabb0240a9..e950cff6d2 100644 --- a/src/test/regress/expected/partition_prune.out +++ b/src/test/regress/expected/partition_prune.out @@ -120,6 +120,8 @@ explain (costs off) select * from lp where a <> 'a' and a <> 'd'; QUERY PLAN ------------------------------------------------------------- Append + -> Seq Scan on lp_ad + Filter: ((a <> 'a'::bpchar) AND (a <> 'd'::bpchar)) -> Seq Scan on lp_bc Filter: ((a <> 'a'::bpchar) AND (a <> 'd'::bpchar)) -> Seq Scan on lp_ef @@ -128,12 +130,14 @@ explain (costs off) select * from lp where a <> 'a' and a <> 'd'; Filter: ((a <> 'a'::bpchar) AND (a <> 'd'::bpchar)) -> Seq Scan on lp_default Filter: ((a <> 'a'::bpchar) AND (a <> 'd'::bpchar)) -(9 rows) +(11 rows) explain (costs off) select * from lp where a not in ('a', 'd'); QUERY PLAN ------------------------------------------------ Append + -> Seq Scan on lp_ad + Filter: (a <> ALL ('{a,d}'::bpchar[])) -> Seq Scan on lp_bc Filter: (a <> ALL ('{a,d}'::bpchar[])) -> Seq Scan on lp_ef @@ -142,7 +146,7 @@ explain (costs off) select * from lp where a not in ('a', 'd'); Filter: (a <> ALL ('{a,d}'::bpchar[])) -> Seq Scan on lp_default Filter: (a <> ALL ('{a,d}'::bpchar[])) -(9 rows) +(11 rows) -- collation matches the partitioning collation, pruning works create table coll_pruning (a text collate "C") partition by list (a); @@ -208,16 +212,14 @@ explain (costs off) select * from rlp where 1 > a; /* commuted */ (3 rows) explain (costs off) select * from rlp where a <= 1; - QUERY PLAN ---------------------------------------- + QUERY PLAN +-------------------------- Append -> Seq Scan on rlp1 Filter: (a <= 1) -> Seq Scan on rlp2 Filter: (a <= 1) - -> Seq Scan on rlp_default_default - Filter: (a <= 1) -(7 rows) +(5 rows) explain (costs off) select * from rlp where a = 1; QUERY PLAN @@ -519,15 +521,13 @@ explain (costs off) select * from rlp where a <= 31; Filter: (a <= 31) -> Seq Scan on rlp5_1 Filter: (a <= 31) - -> Seq Scan on rlp5_default - Filter: (a <= 31) -> Seq Scan on rlp_default_10 Filter: (a <= 31) -> Seq Scan on rlp_default_30 Filter: (a <= 31) -> Seq Scan on rlp_default_default Filter: (a <= 31) -(29 rows) +(27 rows) explain (costs off) select * from rlp where a = 1 or a = 7; QUERY PLAN @@ -575,9 +575,7 @@ explain (costs off) select * from rlp where a > 20 and a < 27; Filter: ((a > 20) AND (a < 27)) -> Seq Scan on rlp4_2 Filter: ((a > 20) AND (a < 27)) - -> Seq Scan on rlp4_default - Filter: ((a > 20) AND (a < 27)) -(7 rows) +(5 rows) explain (costs off) select * from rlp where a = 29; QUERY PLAN @@ -651,8 +649,6 @@ explain (costs off) select * from rlp where (a = 1 and a = 3) or (a > 1 and a = QUERY PLAN ------------------------------------------------------------------- Append - -> Seq Scan on rlp2 - Filter: (((a = 1) AND (a = 3)) OR ((a > 1) AND (a = 15))) -> Seq Scan on rlp3abcd Filter: (((a = 1) AND (a = 3)) OR ((a > 1) AND (a = 15))) -> Seq Scan on rlp3efgh @@ -661,7 +657,7 @@ explain (costs off) select * from rlp where (a = 1 and a = 3) or (a > 1 and a = Filter: (((a = 1) AND (a = 3)) OR ((a > 1) AND (a = 15))) -> Seq Scan on rlp3_default Filter: (((a = 1) AND (a = 3)) OR ((a > 1) AND (a = 15))) -(11 rows) +(9 rows) -- multi-column keys create table mc3p (a int, b int, c int) partition by range (a, abs(b), c); @@ -716,9 +712,7 @@ explain (costs off) select * from mc3p where a = 1 and abs(b) = 1 and c < 8; Filter: ((c < 8) AND (a = 1) AND (abs(b) = 1)) -> Seq Scan on mc3p1 Filter: ((c < 8) AND (a = 1) AND (abs(b) = 1)) - -> Seq Scan on mc3p_default - Filter: ((c < 8) AND (a = 1) AND (abs(b) = 1)) -(7 rows) +(5 rows) explain (costs off) select * from mc3p where a = 10 and abs(b) between 5 and 35; QUERY PLAN @@ -894,6 +888,8 @@ explain (costs off) select * from mc3p where a = 1 or abs(b) = 1 or c = 1; Filter: ((a = 1) OR (abs(b) = 1) OR (c = 1)) -> Seq Scan on mc3p2 Filter: ((a = 1) OR (abs(b) = 1) OR (c = 1)) + -> Seq Scan on mc3p3 + Filter: ((a = 1) OR (abs(b) = 1) OR (c = 1)) -> Seq Scan on mc3p4 Filter: ((a = 1) OR (abs(b) = 1) OR (c = 1)) -> Seq Scan on mc3p5 @@ -904,7 +900,7 @@ explain (costs off) select * from mc3p where a = 1 or abs(b) = 1 or c = 1; Filter: ((a = 1) OR (abs(b) = 1) OR (c = 1)) -> Seq Scan on mc3p_default Filter: ((a = 1) OR (abs(b) = 1) OR (c = 1)) -(17 rows) +(19 rows) explain (costs off) select * from mc3p where (a = 1 and abs(b) = 1) or (a = 10 and abs(b) = 10); QUERY PLAN @@ -965,9 +961,11 @@ explain (costs off) select * from mc2p where a = 2 and b < 1; QUERY PLAN --------------------------------------- Append + -> Seq Scan on mc2p2 + Filter: ((b < 1) AND (a = 2)) -> Seq Scan on mc2p3 Filter: ((b < 1) AND (a = 2)) -(3 rows) +(5 rows) explain (costs off) select * from mc2p where a > 1; QUERY PLAN @@ -1009,28 +1007,20 @@ explain (costs off) select * from boolpart where a in (true, false); (5 rows) explain (costs off) select * from boolpart where a = false; - QUERY PLAN ------------------------------------- + QUERY PLAN +------------------------------ Append -> Seq Scan on boolpart_f Filter: (NOT a) - -> Seq Scan on boolpart_t - Filter: (NOT a) - -> Seq Scan on boolpart_default - Filter: (NOT a) -(7 rows) +(3 rows) explain (costs off) select * from boolpart where not a = false; - QUERY PLAN ------------------------------------- + QUERY PLAN +------------------------------ Append - -> Seq Scan on boolpart_f - Filter: a -> Seq Scan on boolpart_t Filter: a - -> Seq Scan on boolpart_default - Filter: a -(7 rows) +(3 rows) explain (costs off) select * from boolpart where a is true or a is not true; QUERY PLAN @@ -1040,33 +1030,22 @@ explain (costs off) select * from boolpart where a is true or a is not true; Filter: ((a IS TRUE) OR (a IS NOT TRUE)) -> Seq Scan on boolpart_t Filter: ((a IS TRUE) OR (a IS NOT TRUE)) - -> Seq Scan on boolpart_default - Filter: ((a IS TRUE) OR (a IS NOT TRUE)) -(7 rows) +(5 rows) explain (costs off) select * from boolpart where a is not true; - QUERY PLAN ------------------------------------- + QUERY PLAN +--------------------------------- Append -> Seq Scan on boolpart_f Filter: (a IS NOT TRUE) - -> Seq Scan on boolpart_t - Filter: (a IS NOT TRUE) - -> Seq Scan on boolpart_default - Filter: (a IS NOT TRUE) -(7 rows) +(3 rows) explain (costs off) select * from boolpart where a is not true and a is not false; - QUERY PLAN --------------------------------------------------------- - Append - -> Seq Scan on boolpart_f - Filter: ((a IS NOT TRUE) AND (a IS NOT FALSE)) - -> Seq Scan on boolpart_t - Filter: ((a IS NOT TRUE) AND (a IS NOT FALSE)) - -> Seq Scan on boolpart_default - Filter: ((a IS NOT TRUE) AND (a IS NOT FALSE)) -(7 rows) + QUERY PLAN +-------------------------- + Result + One-Time Filter: false +(2 rows) explain (costs off) select * from boolpart where a is unknown; QUERY PLAN @@ -1092,4 +1071,253 @@ explain (costs off) select * from boolpart where a is not unknown; Filter: (a IS NOT UNKNOWN) (7 rows) -drop table lp, coll_pruning, rlp, mc3p, mc2p, boolpart; +-- hash partitioning +create table hp (a int, b text) partition by hash (a, b); +create table hp0 partition of hp for values with (modulus 4, remainder 0); +create table hp3 partition of hp for values with (modulus 4, remainder 3); +create table hp1 partition of hp for values with (modulus 4, remainder 1); +create table hp2 partition of hp for values with (modulus 4, remainder 2); +insert into hp values (null, null); +insert into hp values (1, null); +insert into hp values (1, 'xxx'); +insert into hp values (null, 'xxx'); +insert into hp values (10, 'xxx'); +insert into hp values (10, 'yyy'); +select tableoid::regclass, * from hp order by 1; + tableoid | a | b +----------+----+----- + hp0 | | + hp0 | 1 | + hp0 | 1 | xxx + hp3 | 10 | yyy + hp1 | | xxx + hp2 | 10 | xxx +(6 rows) + +/* partial keys won't prune, nor would non-equality conditions */ +explain (costs off) select * from hp where a = 1; + QUERY PLAN +------------------------- + Append + -> Seq Scan on hp0 + Filter: (a = 1) + -> Seq Scan on hp1 + Filter: (a = 1) + -> Seq Scan on hp2 + Filter: (a = 1) + -> Seq Scan on hp3 + Filter: (a = 1) +(9 rows) + +explain (costs off) select * from hp where b = 'xxx'; + QUERY PLAN +----------------------------------- + Append + -> Seq Scan on hp0 + Filter: (b = 'xxx'::text) + -> Seq Scan on hp1 + Filter: (b = 'xxx'::text) + -> Seq Scan on hp2 + Filter: (b = 'xxx'::text) + -> Seq Scan on hp3 + Filter: (b = 'xxx'::text) +(9 rows) + +explain (costs off) select * from hp where a is null; + QUERY PLAN +----------------------------- + Append + -> Seq Scan on hp0 + Filter: (a IS NULL) + -> Seq Scan on hp1 + Filter: (a IS NULL) + -> Seq Scan on hp2 + Filter: (a IS NULL) + -> Seq Scan on hp3 + Filter: (a IS NULL) +(9 rows) + +explain (costs off) select * from hp where b is null; + QUERY PLAN +----------------------------- + Append + -> Seq Scan on hp0 + Filter: (b IS NULL) + -> Seq Scan on hp1 + Filter: (b IS NULL) + -> Seq Scan on hp2 + Filter: (b IS NULL) + -> Seq Scan on hp3 + Filter: (b IS NULL) +(9 rows) + +explain (costs off) select * from hp where a < 1 and b = 'xxx'; + QUERY PLAN +------------------------------------------------- + Append + -> Seq Scan on hp0 + Filter: ((a < 1) AND (b = 'xxx'::text)) + -> Seq Scan on hp1 + Filter: ((a < 1) AND (b = 'xxx'::text)) + -> Seq Scan on hp2 + Filter: ((a < 1) AND (b = 'xxx'::text)) + -> Seq Scan on hp3 + Filter: ((a < 1) AND (b = 'xxx'::text)) +(9 rows) + +explain (costs off) select * from hp where a <> 1 and b = 'yyy'; + QUERY PLAN +-------------------------------------------------- + Append + -> Seq Scan on hp0 + Filter: ((a <> 1) AND (b = 'yyy'::text)) + -> Seq Scan on hp1 + Filter: ((a <> 1) AND (b = 'yyy'::text)) + -> Seq Scan on hp2 + Filter: ((a <> 1) AND (b = 'yyy'::text)) + -> Seq Scan on hp3 + Filter: ((a <> 1) AND (b = 'yyy'::text)) +(9 rows) + +/* pruning should work in all cases below */ +explain (costs off) select * from hp where a is null and b is null; + QUERY PLAN +----------------------------------------------- + Append + -> Seq Scan on hp0 + Filter: ((a IS NULL) AND (b IS NULL)) +(3 rows) + +explain (costs off) select * from hp where a = 1 and b is null; + QUERY PLAN +------------------------------------------- + Append + -> Seq Scan on hp0 + Filter: ((b IS NULL) AND (a = 1)) +(3 rows) + +explain (costs off) select * from hp where a = 1 and b = 'xxx'; + QUERY PLAN +------------------------------------------------- + Append + -> Seq Scan on hp0 + Filter: ((a = 1) AND (b = 'xxx'::text)) +(3 rows) + +explain (costs off) select * from hp where a is null and b = 'xxx'; + QUERY PLAN +----------------------------------------------------- + Append + -> Seq Scan on hp1 + Filter: ((a IS NULL) AND (b = 'xxx'::text)) +(3 rows) + +explain (costs off) select * from hp where a = 10 and b = 'xxx'; + QUERY PLAN +-------------------------------------------------- + Append + -> Seq Scan on hp2 + Filter: ((a = 10) AND (b = 'xxx'::text)) +(3 rows) + +explain (costs off) select * from hp where a = 10 and b = 'yyy'; + QUERY PLAN +-------------------------------------------------- + Append + -> Seq Scan on hp3 + Filter: ((a = 10) AND (b = 'yyy'::text)) +(3 rows) + +explain (costs off) select * from hp where (a = 10 and b = 'yyy') or (a = 10 and b = 'xxx') or (a is null and b is null); + QUERY PLAN +------------------------------------------------------------------------------------------------------------------------- + Append + -> Seq Scan on hp0 + Filter: (((a = 10) AND (b = 'yyy'::text)) OR ((a = 10) AND (b = 'xxx'::text)) OR ((a IS NULL) AND (b IS NULL))) + -> Seq Scan on hp2 + Filter: (((a = 10) AND (b = 'yyy'::text)) OR ((a = 10) AND (b = 'xxx'::text)) OR ((a IS NULL) AND (b IS NULL))) + -> Seq Scan on hp3 + Filter: (((a = 10) AND (b = 'yyy'::text)) OR ((a = 10) AND (b = 'xxx'::text)) OR ((a IS NULL) AND (b IS NULL))) +(7 rows) + +-- some more cases +-- pruning for partitioned table appearing inside a sub-query +-- pruning won't work for mc3p, because some keys are Params +explain (costs off) select * from mc2p t1, lateral (select count(*) from mc3p t2 where t2.a = t1.b and abs(t2.b) = 1 and t2.c = 1) s where t1.a = 1; + QUERY PLAN +----------------------------------------------------------------------- + Nested Loop + -> Append + -> Seq Scan on mc2p0 t1 + Filter: (a = 1) + -> Seq Scan on mc2p1 t1_1 + Filter: (a = 1) + -> Seq Scan on mc2p2 t1_2 + Filter: (a = 1) + -> Seq Scan on mc2p_default t1_3 + Filter: (a = 1) + -> Aggregate + -> Append + -> Seq Scan on mc3p0 t2 + Filter: ((a = t1.b) AND (c = 1) AND (abs(b) = 1)) + -> Seq Scan on mc3p1 t2_1 + Filter: ((a = t1.b) AND (c = 1) AND (abs(b) = 1)) + -> Seq Scan on mc3p2 t2_2 + Filter: ((a = t1.b) AND (c = 1) AND (abs(b) = 1)) + -> Seq Scan on mc3p3 t2_3 + Filter: ((a = t1.b) AND (c = 1) AND (abs(b) = 1)) + -> Seq Scan on mc3p4 t2_4 + Filter: ((a = t1.b) AND (c = 1) AND (abs(b) = 1)) + -> Seq Scan on mc3p5 t2_5 + Filter: ((a = t1.b) AND (c = 1) AND (abs(b) = 1)) + -> Seq Scan on mc3p6 t2_6 + Filter: ((a = t1.b) AND (c = 1) AND (abs(b) = 1)) + -> Seq Scan on mc3p7 t2_7 + Filter: ((a = t1.b) AND (c = 1) AND (abs(b) = 1)) + -> Seq Scan on mc3p_default t2_8 + Filter: ((a = t1.b) AND (c = 1) AND (abs(b) = 1)) +(30 rows) + +-- pruning should work fine, because prefix of keys is available +explain (costs off) select * from mc2p t1, lateral (select count(*) from mc3p t2 where t2.c = t1.b and abs(t2.b) = 1 and t2.a = 1) s where t1.a = 1; + QUERY PLAN +----------------------------------------------------------------------- + Nested Loop + -> Append + -> Seq Scan on mc2p0 t1 + Filter: (a = 1) + -> Seq Scan on mc2p1 t1_1 + Filter: (a = 1) + -> Seq Scan on mc2p2 t1_2 + Filter: (a = 1) + -> Seq Scan on mc2p_default t1_3 + Filter: (a = 1) + -> Aggregate + -> Append + -> Seq Scan on mc3p0 t2 + Filter: ((c = t1.b) AND (a = 1) AND (abs(b) = 1)) + -> Seq Scan on mc3p1 t2_1 + Filter: ((c = t1.b) AND (a = 1) AND (abs(b) = 1)) +(16 rows) + +-- pruning should work fine in this case, too. +explain (costs off) select * from mc2p t1, lateral (select count(*) from mc3p t2 where t2.a = 1 and abs(t2.b) = 1 and t2.c = 1) s where t1.a = 1; + QUERY PLAN +-------------------------------------------------------------------- + Nested Loop + -> Aggregate + -> Append + -> Seq Scan on mc3p1 t2 + Filter: ((a = 1) AND (c = 1) AND (abs(b) = 1)) + -> Append + -> Seq Scan on mc2p0 t1 + Filter: (a = 1) + -> Seq Scan on mc2p1 t1_1 + Filter: (a = 1) + -> Seq Scan on mc2p2 t1_2 + Filter: (a = 1) + -> Seq Scan on mc2p_default t1_3 + Filter: (a = 1) +(14 rows) + +drop table lp, coll_pruning, rlp, mc3p, mc2p, boolpart, hp; diff --git a/src/test/regress/sql/partition_prune.sql b/src/test/regress/sql/partition_prune.sql index 514f8e5ce1..72dae80e8a 100644 --- a/src/test/regress/sql/partition_prune.sql +++ b/src/test/regress/sql/partition_prune.sql @@ -152,4 +152,49 @@ explain (costs off) select * from boolpart where a is not true and a is not fals explain (costs off) select * from boolpart where a is unknown; explain (costs off) select * from boolpart where a is not unknown; -drop table lp, coll_pruning, rlp, mc3p, mc2p, boolpart; +-- hash partitioning +create table hp (a int, b text) partition by hash (a, b); +create table hp0 partition of hp for values with (modulus 4, remainder 0); +create table hp3 partition of hp for values with (modulus 4, remainder 3); +create table hp1 partition of hp for values with (modulus 4, remainder 1); +create table hp2 partition of hp for values with (modulus 4, remainder 2); + +insert into hp values (null, null); +insert into hp values (1, null); +insert into hp values (1, 'xxx'); +insert into hp values (null, 'xxx'); +insert into hp values (10, 'xxx'); +insert into hp values (10, 'yyy'); +select tableoid::regclass, * from hp order by 1; + +/* partial keys won't prune, nor would non-equality conditions */ +explain (costs off) select * from hp where a = 1; +explain (costs off) select * from hp where b = 'xxx'; +explain (costs off) select * from hp where a is null; +explain (costs off) select * from hp where b is null; +explain (costs off) select * from hp where a < 1 and b = 'xxx'; +explain (costs off) select * from hp where a <> 1 and b = 'yyy'; + +/* pruning should work in all cases below */ +explain (costs off) select * from hp where a is null and b is null; +explain (costs off) select * from hp where a = 1 and b is null; +explain (costs off) select * from hp where a = 1 and b = 'xxx'; +explain (costs off) select * from hp where a is null and b = 'xxx'; +explain (costs off) select * from hp where a = 10 and b = 'xxx'; +explain (costs off) select * from hp where a = 10 and b = 'yyy'; +explain (costs off) select * from hp where (a = 10 and b = 'yyy') or (a = 10 and b = 'xxx') or (a is null and b is null); + +-- some more cases + +-- pruning for partitioned table appearing inside a sub-query + +-- pruning won't work for mc3p, because some keys are Params +explain (costs off) select * from mc2p t1, lateral (select count(*) from mc3p t2 where t2.a = t1.b and abs(t2.b) = 1 and t2.c = 1) s where t1.a = 1; + +-- pruning should work fine, because prefix of keys is available +explain (costs off) select * from mc2p t1, lateral (select count(*) from mc3p t2 where t2.c = t1.b and abs(t2.b) = 1 and t2.a = 1) s where t1.a = 1; + +-- pruning should work fine in this case, too. +explain (costs off) select * from mc2p t1, lateral (select count(*) from mc3p t2 where t2.a = 1 and abs(t2.b) = 1 and t2.c = 1) s where t1.a = 1; + +drop table lp, coll_pruning, rlp, mc3p, mc2p, boolpart, hp; -- 2.11.0