From c658acad1fea6d0d254cbf3bfea7bdbe017a1eeb Mon Sep 17 00:00:00 2001 From: amit Date: Wed, 18 Oct 2017 17:14:53 +0900 Subject: [PATCH 8/8] Implement get_partitions_for_keys Disable constraint_exclusion pruning using internal partition constraints for select queries, because we've now got the new pruning working. --- src/backend/catalog/partition.c | 431 +++++++++++++++++++++++++++++++- src/backend/optimizer/util/plancat.c | 29 ++- src/test/regress/expected/inherit.out | 8 +- src/test/regress/expected/partition.out | 345 +++++++++++++++++++++---- src/test/regress/sql/partition.sql | 47 +++- 5 files changed, 788 insertions(+), 72 deletions(-) diff --git a/src/backend/catalog/partition.c b/src/backend/catalog/partition.c index 2f4501576a..f07ac1529e 100644 --- a/src/backend/catalog/partition.c +++ b/src/backend/catalog/partition.c @@ -2784,10 +2784,437 @@ partition_cmp_args(PartitionKey key, int partattoff, static Bitmapset * get_partitions_for_keys(Relation rel, PartScanKeyInfo *keys) { - PartitionDesc partdesc = RelationGetPartitionDesc(rel); + PartitionKey partkey = RelationGetPartitionKey(rel); + PartitionDesc partdesc = RelationGetPartitionDesc(rel); + PartitionBoundInfo boundinfo = partdesc->boundinfo; Bitmapset *result = NULL; + PartitionBoundCmpArg arg; + int i, + eqoff, + minoff, + maxoff; + bool is_equal; + bool hash_isnull[PARTITION_MAX_KEYS]; + + /* Return an empty set if no partitions to see. */ + if (partdesc->nparts == 0) + return NULL; + + memset(hash_isnull, false, sizeof(hash_isnull)); + /* Handle null partition keys. */ + for (i = 0; i < partkey->partnatts; i++) + { + if (keys->keyisnull[i]) + { + int other_idx = -1; + + switch (partkey->strategy) + { + /* + * Hash partitioning handles puts nulls into a normal + * partition and doesn't require to define a special + * null-accpting partition. So, we let this fall through + * get handled by the code below that handles equality + * keys. + */ + case PARTITION_STRATEGY_HASH: + hash_isnull[i] = true; + keys->n_eqkeys++; + break; + + /* + * In range and list partitioning cases, only a designated + * partition will accept nulls. + */ + case PARTITION_STRATEGY_LIST: + case PARTITION_STRATEGY_RANGE: + if (partition_bound_accepts_nulls(boundinfo)|| + partition_bound_has_default(boundinfo)) + other_idx = partition_bound_accepts_nulls(boundinfo) + ? boundinfo->null_index + : boundinfo->default_index; + if (other_idx >= 0) + result = bms_make_singleton(other_idx); + return result; + } + } + } + + /* + * If there are no datums to compare keys with, but there exists a + * partition, the latter must be a partition that accepts only nulls + * or a default partition. If it is the former and we didn't already + * return it as the only scannable partition, that means the query + * doesn't want null values in its output. So, all of what the query + * wants instead must be in the default partition. + */ + if (boundinfo->ndatums == 0) + { + if (partition_bound_has_default(boundinfo)) + result = bms_make_singleton(boundinfo->default_index); + return result; + } + + + /* + * Determine set of partitions using provided keys, which proceeds in a + * manner determined by the partitioning method. + */ + if (keys->n_eqkeys == partkey->partnatts) + { + Assert(keys->n_eqkeys == partkey->partnatts); + switch (partkey->strategy) + { + /* Hash-partitioning is real simple. */ + case PARTITION_STRATEGY_HASH: + { + uint64 rowHash; + int greatest_modulus = get_greatest_modulus(boundinfo), + result_index; + + rowHash = compute_hash_value(partkey, keys->eqkeys, + hash_isnull); + result_index = boundinfo->indexes[rowHash % greatest_modulus]; + if (result_index >= 0) + result = bms_make_singleton(result_index); + + return result; + } + + /* Range and list partitioning take a bit more work. */ + + case PARTITION_STRATEGY_LIST: + memset(&arg, 0, sizeof(PartitionBoundCmpArg)); + arg.datums = keys->eqkeys; + arg.ndatums = keys->n_eqkeys; + eqoff = partition_bound_bsearch(partkey, boundinfo, &arg, + &is_equal); + /* For list partition, must exactly match the datum. */ + if (eqoff >= 0 && !is_equal) + eqoff = -1; + break; + + case PARTITION_STRATEGY_RANGE: + memset(&arg, 0, sizeof(PartitionBoundCmpArg)); + arg.datums = keys->eqkeys; + arg.ndatums = keys->n_eqkeys; + eqoff = partition_bound_bsearch(partkey, boundinfo, &arg, + &is_equal); + /* + * eqoff is gives us the bound that is known to be <= + * eqkeys given how partition_bound_bsearch works. The + * bound at eqoff + 1, then, would be the upper bound of + * the only partition that needs to be scanned. + */ + if (eqoff >= 0) + eqoff += 1; + break; + } + + /* + * Ask later code to include the default partition, because eqkeys + * didn't identify a specific partition or identified a range + * of unassigned values. + */ + if (eqoff >= 0 && boundinfo->indexes[eqoff] >= 0) + result = bms_make_singleton(boundinfo->indexes[eqoff]); + else if (partition_bound_has_default(boundinfo)) + result = bms_make_singleton(boundinfo->default_index); + + /* There are no minkeys and maxkeys when eqkeys is valid. */ + return result; + } + + /* + * Hash partitioning doesn't understand non-equality conditions, so + * return all partitions. + */ + if (partkey->strategy == PARTITION_STRATEGY_HASH) + { + result = bms_add_range(result, 0, partdesc->nparts - 1); + return result; + } + + /* + * Find the leftmost bound that satisfies the query, i.e., one that + * satisfies minkeys. + */ + minoff = 0; + if (keys->n_minkeys > 0) + { + memset(&arg, 0, sizeof(PartitionBoundCmpArg)); + arg.datums = keys->minkeys; + arg.ndatums = keys->n_minkeys; + minoff = partition_bound_bsearch(partkey, boundinfo, &arg, &is_equal); + + switch (partkey->strategy) + { + case PARTITION_STRATEGY_LIST: + /* + * minoff set to -1 means all datums are greater than minkeys, + * which means all partitions satisfy minkeys. In that case, + * set minoff to the index of the leftmost datum, viz. 0. + * + * If the bound at minoff doesn't exactly match minkey or if + * it does but minkey isn't inclusive, move to the bound on + * the right. + */ + if (minoff == -1 || !is_equal || !keys->min_incl) + minoff++; + + /* + * boundinfo->ndatums - 1 is the last valid list partition datums + * index. + */ + if (minoff > boundinfo->ndatums - 1) + minoff = -1; + break; + + case PARTITION_STRATEGY_RANGE: + /* + * If only a prefix of the whole partition key is provided, + * there will be multiple partitions whose bound share the + * same prefix. If minkey is inclusive, we must make minoff + * point to the leftmost such bound, making the result contain + * all such partitions. If it is exclusive, we must move + * minoff to the right such that minoff points to the first + * partition whose bound is greater than this prefix, thus + * excluding all aforementioned partitions from appearing in + * the result. + */ + if (is_equal && arg.ndatums < partkey->partnatts) + { + int32 cmpval; + + is_equal = false; + do + { + if (keys->min_incl) + minoff -= 1; + else + minoff += 1; + if (minoff < 0 || minoff >= boundinfo->ndatums) + break; + cmpval = partition_bound_cmp(partkey, boundinfo, + minoff, &arg); + } while (cmpval == 0); + + /* Back up if went too far. */ + if (!keys->min_incl) + minoff -= 1; + } + + /* + * At this point, minoff gives us the leftmost bound that is + * known to be <= query's minkey. The bound at minoff + 1 (if + * there is one), then, would be the upper bound of the + * leftmost partition that needs to be scanned. + */ + minoff += 1; + break; + } + } + + /* + * Find the rightmost bound that satisfies the query, i.e., one that + * satisfies maxkeys. + */ + if (partkey->strategy == PARTITION_STRATEGY_RANGE) + /* 1 more index than datums in this case */ + maxoff = boundinfo->ndatums; + else + maxoff = boundinfo->ndatums - 1; + if (keys->n_maxkeys > 0) + { + memset(&arg, 0, sizeof(PartitionBoundCmpArg)); + arg.datums = keys->maxkeys; + arg.ndatums = keys->n_maxkeys; + maxoff = partition_bound_bsearch(partkey, boundinfo, &arg, &is_equal); + + switch (partkey->strategy) + { + case PARTITION_STRATEGY_LIST: + /* + * Unlike minoff, we leave maxoff that is set to -1 unchanged, + * because it simply means none of the partitions satisfies + * maxkeys. + * + * If the bound at maxoff exactly matches maxkey (is_equal), + * but the maxkey is not inclusive, then go to the bound on + * left. + */ + if (is_equal && !keys->max_incl) + maxoff--; + + /* + * maxoff may have become -1, which again means no partition + * satisfies the maxkeys. + */ + break; + + case PARTITION_STRATEGY_RANGE: + /* See the comment above for minkeys. */ + if (is_equal && arg.ndatums < partkey->partnatts) + { + int32 cmpval; + + is_equal = false; + do + { + if (keys->max_incl) + maxoff += 1; + else + maxoff -= 1; + if (maxoff < 0 || maxoff >= boundinfo->ndatums) + break; + cmpval = partition_bound_cmp(partkey, boundinfo, + maxoff, &arg); + } while (cmpval == 0); + + /* Back up if went too far. */ + if (keys->max_incl) + maxoff -= 1; + } + + /* + * At this point, maxoff gives us the rightmost bound that is + * known to be <= query's maxkey. The bound at maxoff + 1, + * then, would be the upper bound of the rightmost partition + * that needs to be scanned. Although, if the bound is equal + * to maxkeys and the latter is not inclusive, then the bound + * at maxoff itself is the upper bound of the rightmost + * partition that needs to be scanned. + */ + if (!is_equal || keys->max_incl) + maxoff += 1; + + break; + } + } + + /* + * minoff or maxoff set to -1 means none of the datums in + * PartitionBoundInfo satisfies both minkeys and maxkeys. If both are set + * to a valid datum offset, that means there exists at least some + * datums (and hence partitions) satisfying both minkeys and maxkeys. + */ + if (minoff >= 0 && maxoff >= 0) + { + bool list_include_def = false, + range_include_def = false; + + switch (partkey->strategy) + { + case PARTITION_STRATEGY_LIST: + /* + * All datums between those at minoff and maxoff satisfy the + * query keys, so add the corresponding partitions to the + * result set. + */ + for (i = minoff; i <= maxoff; i++) + result = bms_add_member(result, boundinfo->indexes[i]); + + /* + * For range queries, always include the default list + * partition. Because list partitions divide the key space + * in a discontinuous manner, not all values in the given + * range will have a partition assigned. + */ + list_include_def = true; + break; + + case PARTITION_STRATEGY_RANGE: + /* + * If the bound at minoff or maxoff looks like it's an upper + * bound of an unassigned range of values, move to the + * adjacent bound which must be the upper bound of the + * leftmost or rightmost partition, respectively, that needs + * to be scanned. + * + * By doing that, we skip over a portion of values that do + * indeed satisfy the query, but don't have a valid partition + * assigned. The default partition would've been included to + * cover those values. Although, if the original bound in + * question is an infinite value, there would not be any + * unassigned range to speak of, because the range is unbounded + * in that direction by definition, so no need to include the + * default. + */ + if (boundinfo->indexes[minoff] < 0) + { + int lastkey = partkey->partnatts - 1; - result = bms_add_range(result, 0, partdesc->nparts - 1); + if (keys->n_minkeys > 0) + lastkey = keys->n_minkeys - 1; + if (minoff >=0 && minoff < boundinfo->ndatums && + boundinfo->kind[minoff][lastkey] == + PARTITION_RANGE_DATUM_VALUE) + { + range_include_def = true; + } + minoff += 1; + } + + if (maxoff >= 1 && boundinfo->indexes[maxoff] < 0) + { + int lastkey = partkey->partnatts - 1; + + if (keys->n_maxkeys > 0) + lastkey = keys->n_maxkeys - 1; + if (maxoff >=0 && maxoff <= boundinfo->ndatums && + boundinfo->kind[maxoff - 1][lastkey] == + PARTITION_RANGE_DATUM_VALUE) + { + range_include_def = true; + } + maxoff -= 1; + } + + if (minoff <= maxoff) + result = bms_add_range(result, + boundinfo->indexes[minoff], + boundinfo->indexes[maxoff]); + /* + * There might exist a range of values unassigned to any + * non-default range partition between the datums at + * minoff and maxoff. + */ + for (i = minoff; i <= maxoff; i++) + { + if (boundinfo->indexes[i] < 0) + { + range_include_def = true; + break; + } + } + + /* + * Since partition keys will nulls are mapped to default + * range partition, we must include the default partition + * if certain keys could be null. + */ + if (keys->n_minkeys < partkey->partnatts || + keys->n_maxkeys < partkey->partnatts) + { + for (i = 0; i < partkey->partnatts; i++) + { + if (!keys->keyisnotnull[i]) + { + range_include_def = true; + break; + } + } + } + + break; + } + + if ((list_include_def || range_include_def) && + partition_bound_has_default(boundinfo)) + result = bms_add_member(result, boundinfo->default_index); + } + else if (partition_bound_has_default(boundinfo)) + result = bms_add_member(result, boundinfo->default_index); return result; } diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c index e1ef936e68..6826f5fc9d 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); diff --git a/src/test/regress/expected/inherit.out b/src/test/regress/expected/inherit.out index fac7b62f9c..5a74151c8f 100644 --- a/src/test/regress/expected/inherit.out +++ b/src/test/regress/expected/inherit.out @@ -1713,11 +1713,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 @@ -1904,11 +1902,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.out b/src/test/regress/expected/partition.out index d44ff4f608..400e97eb94 100644 --- a/src/test/regress/expected/partition.out +++ b/src/test/regress/expected/partition.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; /* commutates */ (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); @@ -692,7 +688,9 @@ explain (costs off) select * from mc3p where a = 1 and abs(b) < 1; Append -> Seq Scan on mc3p0 Filter: ((a = 1) AND (abs(b) < 1)) -(3 rows) + -> Seq Scan on mc3p_default + Filter: ((a = 1) AND (abs(b) < 1)) +(5 rows) explain (costs off) select * from mc3p where a = 1 and abs(b) = 1; QUERY PLAN @@ -714,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 @@ -813,12 +809,14 @@ explain (costs off) select * from mc3p where a = 20 and abs(b) = 10 and c = 100; (3 rows) explain (costs off) select * from mc3p where a > 20; - QUERY PLAN --------------------------- + QUERY PLAN +-------------------------------- Append -> Seq Scan on mc3p7 Filter: (a > 20) -(3 rows) + -> Seq Scan on mc3p_default + Filter: (a > 20) +(5 rows) explain (costs off) select * from mc3p where a >= 20; QUERY PLAN @@ -844,7 +842,9 @@ explain (costs off) select * from mc3p where (a = 1 and abs(b) = 1 and c = 1) or Filter: (((a = 1) AND (abs(b) = 1) AND (c = 1)) OR ((a = 10) AND (abs(b) = 5) AND (c = 10)) OR ((a > 11) AND (a < 20))) -> Seq Scan on mc3p5 Filter: (((a = 1) AND (abs(b) = 1) AND (c = 1)) OR ((a = 10) AND (abs(b) = 5) AND (c = 10)) OR ((a > 11) AND (a < 20))) -(7 rows) + -> Seq Scan on mc3p_default + Filter: (((a = 1) AND (abs(b) = 1) AND (c = 1)) OR ((a = 10) AND (abs(b) = 5) AND (c = 10)) OR ((a > 11) AND (a < 20))) +(9 rows) explain (costs off) select * from mc3p where (a = 1 and abs(b) = 1 and c = 1) or (a = 10 and abs(b) = 5 and c = 10) or (a > 11 and a < 20) or a < 1; QUERY PLAN @@ -858,7 +858,9 @@ explain (costs off) select * from mc3p where (a = 1 and abs(b) = 1 and c = 1) or Filter: (((a = 1) AND (abs(b) = 1) AND (c = 1)) OR ((a = 10) AND (abs(b) = 5) AND (c = 10)) OR ((a > 11) AND (a < 20)) OR (a < 1)) -> Seq Scan on mc3p5 Filter: (((a = 1) AND (abs(b) = 1) AND (c = 1)) OR ((a = 10) AND (abs(b) = 5) AND (c = 10)) OR ((a > 11) AND (a < 20)) OR (a < 1)) -(9 rows) + -> Seq Scan on mc3p_default + Filter: (((a = 1) AND (abs(b) = 1) AND (c = 1)) OR ((a = 10) AND (abs(b) = 5) AND (c = 10)) OR ((a > 11) AND (a < 20)) OR (a < 1)) +(11 rows) explain (costs off) select * from mc3p where (a = 1 and abs(b) = 1 and c = 1) or (a = 10 and abs(b) = 5 and c = 10) or (a > 11 and a < 20) or a < 1 or a = 1; QUERY PLAN @@ -886,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 @@ -896,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 @@ -957,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 @@ -1001,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 @@ -1032,21 +1030,15 @@ 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 @@ -1079,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.sql b/src/test/regress/sql/partition.sql index 9dfcbe1e70..2a623afd2f 100644 --- a/src/test/regress/sql/partition.sql +++ b/src/test/regress/sql/partition.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