diff --git a/doc/src/sgml/config.sgml b/doc/src/sgml/config.sgml index 5d5f2d23c4f..eabe2a92352 100644 --- a/doc/src/sgml/config.sgml +++ b/doc/src/sgml/config.sgml @@ -3826,6 +3826,23 @@ ANY num_sync ( + enable_partition_pruning (boolean) + + enable_partition_pruning configuration parameter + + + + + Enables or disables the query planner's ability to eliminate a + partitioned table's partitions from query plans. This also controls + the planner's ability to generate query plans which allow the query + executor to remove (ignore) partitions during query execution. The + default is on. + + + + enable_partitionwise_join (boolean) @@ -4417,8 +4434,7 @@ ANY num_sync ( + Ensure that the configuration parameter is not disabled in postgresql.conf. If it is, queries will not be optimized as desired. diff --git a/src/backend/nodes/outfuncs.c b/src/backend/nodes/outfuncs.c index 3991a0ce83a..f2d00c5e312 100644 --- a/src/backend/nodes/outfuncs.c +++ b/src/backend/nodes/outfuncs.c @@ -2291,7 +2291,7 @@ _outPlannerInfo(StringInfo str, const PlannerInfo *node) WRITE_FLOAT_FIELD(tuple_fraction, "%.4f"); WRITE_FLOAT_FIELD(limit_tuples, "%.0f"); WRITE_UINT_FIELD(qual_security_level); - WRITE_BOOL_FIELD(hasInheritedTarget); + WRITE_ENUM_FIELD(inhTargetKind, InheritanceKind); WRITE_BOOL_FIELD(hasJoinRTEs); WRITE_BOOL_FIELD(hasLateralRTEs); WRITE_BOOL_FIELD(hasDeletedRTEs); diff --git a/src/backend/optimizer/path/allpaths.c b/src/backend/optimizer/path/allpaths.c index 3ba3f87eb7c..9ed73da0f79 100644 --- a/src/backend/optimizer/path/allpaths.c +++ b/src/backend/optimizer/path/allpaths.c @@ -901,7 +901,8 @@ set_append_rel_size(PlannerInfo *root, RelOptInfo *rel, * store the relids of all partitions which could possibly contain a * matching tuple, and skip anything else in the loop below. */ - if (rte->relkind == RELKIND_PARTITIONED_TABLE && + if (enable_partition_pruning && + rte->relkind == RELKIND_PARTITIONED_TABLE && rel->baserestrictinfo != NIL) { live_children = prune_append_rel_partitions(rel); diff --git a/src/backend/optimizer/path/costsize.c b/src/backend/optimizer/path/costsize.c index 957f751bd48..a2a7e0c5202 100644 --- a/src/backend/optimizer/path/costsize.c +++ b/src/backend/optimizer/path/costsize.c @@ -138,6 +138,7 @@ bool enable_partitionwise_join = false; bool enable_partitionwise_aggregate = false; bool enable_parallel_append = true; bool enable_parallel_hash = true; +bool enable_partition_pruning = true; typedef struct { diff --git a/src/backend/optimizer/plan/createplan.c b/src/backend/optimizer/plan/createplan.c index 280f21cd45c..0317763f43c 100644 --- a/src/backend/optimizer/plan/createplan.c +++ b/src/backend/optimizer/plan/createplan.c @@ -1077,7 +1077,8 @@ create_append_plan(PlannerInfo *root, AppendPath *best_path) subplans = lappend(subplans, subplan); } - if (rel->reloptkind == RELOPT_BASEREL && + if (enable_partition_pruning && + rel->reloptkind == RELOPT_BASEREL && best_path->partitioned_rels != NIL) { List *prunequal; @@ -1979,7 +1980,7 @@ create_groupingsets_plan(PlannerInfo *root, GroupingSetsPath *best_path) * create_modifytable_plan). Fortunately we can't be because there would * never be grouping in an UPDATE/DELETE; but let's Assert that. */ - Assert(!root->hasInheritedTarget); + Assert(root->inhTargetKind == INHKIND_NONE); Assert(root->grouping_map == NULL); root->grouping_map = grouping_map; @@ -2141,7 +2142,7 @@ create_minmaxagg_plan(PlannerInfo *root, MinMaxAggPath *best_path) * create_modifytable_plan). Fortunately we can't be because there would * never be aggregates in an UPDATE/DELETE; but let's Assert that. */ - Assert(!root->hasInheritedTarget); + Assert(root->inhTargetKind == INHKIND_NONE); Assert(root->minmax_aggs == NIL); root->minmax_aggs = best_path->mmaggregates; diff --git a/src/backend/optimizer/plan/planner.c b/src/backend/optimizer/plan/planner.c index 2e298f83573..24e6ee026e1 100644 --- a/src/backend/optimizer/plan/planner.c +++ b/src/backend/optimizer/plan/planner.c @@ -623,7 +623,7 @@ subquery_planner(PlannerGlobal *glob, Query *parse, root->grouping_map = NULL; root->minmax_aggs = NIL; root->qual_security_level = 0; - root->hasInheritedTarget = false; + root->inhTargetKind = INHKIND_NONE; root->hasRecursion = hasRecursion; if (hasRecursion) root->wt_param_id = SS_assign_special_param(root); @@ -1424,8 +1424,13 @@ inheritance_planner(PlannerInfo *root) Assert(subroot->join_info_list == NIL); /* and we haven't created PlaceHolderInfos, either */ Assert(subroot->placeholder_list == NIL); - /* hack to mark target relation as an inheritance partition */ - subroot->hasInheritedTarget = true; + + /* + * Mark if we're planning a query to a partitioned table or an + * inheritance parent. + */ + subroot->inhTargetKind = + partitioned_relids ? INHKIND_PARTITIONED : INHKIND_INHERITED; /* * If the child is further partitioned, remember it as a parent. Since diff --git a/src/backend/optimizer/prep/prepjointree.c b/src/backend/optimizer/prep/prepjointree.c index 45d82da4591..c3f46a26c3a 100644 --- a/src/backend/optimizer/prep/prepjointree.c +++ b/src/backend/optimizer/prep/prepjointree.c @@ -914,7 +914,7 @@ pull_up_simple_subquery(PlannerInfo *root, Node *jtnode, RangeTblEntry *rte, subroot->grouping_map = NULL; subroot->minmax_aggs = NIL; subroot->qual_security_level = 0; - subroot->hasInheritedTarget = false; + subroot->inhTargetKind = INHKIND_NONE; subroot->hasRecursion = false; subroot->wt_param_id = -1; subroot->non_recursive_path = NULL; diff --git a/src/backend/optimizer/util/plancat.c b/src/backend/optimizer/util/plancat.c index 1ff0ef4866b..6973fe34586 100644 --- a/src/backend/optimizer/util/plancat.c +++ b/src/backend/optimizer/util/plancat.c @@ -1272,7 +1272,7 @@ get_relation_constraints(PlannerInfo *root, * descriptor, instead of constraint exclusion which is driven by the * individual partition's partition constraint. */ - if (root->parse->commandType != CMD_SELECT) + if (enable_partition_pruning && root->parse->commandType != CMD_SELECT) { List *pcqual = RelationGetPartitionQual(relation); @@ -1415,14 +1415,41 @@ relation_excluded_by_constraints(PlannerInfo *root, return true; } - /* Skip further tests if constraint exclusion is disabled for the rel */ - if (constraint_exclusion == CONSTRAINT_EXCLUSION_OFF || - (constraint_exclusion == CONSTRAINT_EXCLUSION_PARTITION && - !(rel->reloptkind == RELOPT_OTHER_MEMBER_REL || - (root->hasInheritedTarget && - rel->reloptkind == RELOPT_BASEREL && - rel->relid == root->parse->resultRelation)))) - return false; + /* + * Skip further tests, depending on constraint_exclusion. + */ + switch (constraint_exclusion) + { + case CONSTRAINT_EXCLUSION_OFF: + /* + * Don't prune if feature turned off -- except if the relation is + * a partition. While partprune.c-style partition pruning is not + * yet in use for all cases (update/delete is not handled), it + * would be a UI horror to use different user-visible controls + * depending on such a volatile implementation detail. Therefore, + * for partitioned tables we use enable_partition_pruning to + * control this behavior. + */ + if (root->inhTargetKind == INHKIND_PARTITIONED) + break; + return false; + + case CONSTRAINT_EXCLUSION_PARTITION: + /* + * When constraint_exclusion is set to 'partition' we only handle + * OTHER_MEMBER_RELs, or BASERELs in cases where the result target + * is an inheritance parent or a partitioned table. + */ + if ((rel->reloptkind != RELOPT_OTHER_MEMBER_REL) && + !(rel->reloptkind == RELOPT_BASEREL && + root->inhTargetKind != INHKIND_NONE && + rel->relid == root->parse->resultRelation)) + return false; + break; + + case CONSTRAINT_EXCLUSION_ON: + break; /* always try to exclude */ + } /* * Check for self-contradictory restriction clauses. We dare not make diff --git a/src/backend/utils/misc/guc.c b/src/backend/utils/misc/guc.c index fa92ce2e683..44dfa92722c 100644 --- a/src/backend/utils/misc/guc.c +++ b/src/backend/utils/misc/guc.c @@ -951,6 +951,17 @@ static struct config_bool ConfigureNamesBool[] = true, NULL, NULL, NULL }, + { + {"enable_partition_pruning", PGC_USERSET, QUERY_TUNING_METHOD, + gettext_noop("Enable plan-time and run-time partition pruning."), + gettext_noop("Allows the query planner and executor to compare partition " + "bounds to conditions in the query to determine which " + "partitions must be scanned.") + }, + &enable_partition_pruning, + true, + NULL, NULL, NULL + }, { {"geqo", PGC_USERSET, QUERY_TUNING_GEQO, gettext_noop("Enables genetic query optimization."), diff --git a/src/backend/utils/misc/postgresql.conf.sample b/src/backend/utils/misc/postgresql.conf.sample index 66d09388278..3d88e80a204 100644 --- a/src/backend/utils/misc/postgresql.conf.sample +++ b/src/backend/utils/misc/postgresql.conf.sample @@ -308,6 +308,7 @@ #enable_partitionwise_join = off #enable_partitionwise_aggregate = off #enable_parallel_hash = on +#enable_partition_pruning = on # - Planner Cost Constants - diff --git a/src/include/nodes/relation.h b/src/include/nodes/relation.h index 2108b6ab1df..8b153a9d4e8 100644 --- a/src/include/nodes/relation.h +++ b/src/include/nodes/relation.h @@ -82,6 +82,17 @@ typedef enum UpperRelationKind /* NB: UPPERREL_FINAL must be last enum entry; it's used to size arrays */ } UpperRelationKind; +/* + * This enum identifies which type of relation is being planned through the + * inheritance planner. INHKIND_NONE indicates the inheritance planner + * was not used. + */ +typedef enum InheritanceKind +{ + INHKIND_NONE, + INHKIND_INHERITED, + INHKIND_PARTITIONED +} InheritanceKind; /*---------- * PlannerGlobal @@ -298,8 +309,9 @@ typedef struct PlannerInfo Index qual_security_level; /* minimum security_level for quals */ /* Note: qual_security_level is zero if there are no securityQuals */ - bool hasInheritedTarget; /* true if parse->resultRelation is an - * inheritance child rel */ + InheritanceKind inhTargetKind; /* indicates if the target relation is an + * inheritance child or partition or a + * partitioned table */ bool hasJoinRTEs; /* true if any RTEs are RTE_JOIN kind */ bool hasLateralRTEs; /* true if any RTEs are marked LATERAL */ bool hasDeletedRTEs; /* true if any RTE was deleted from jointree */ diff --git a/src/include/optimizer/cost.h b/src/include/optimizer/cost.h index 6e6d0d3c796..55e6a8488fe 100644 --- a/src/include/optimizer/cost.h +++ b/src/include/optimizer/cost.h @@ -71,6 +71,7 @@ extern PGDLLIMPORT bool enable_partitionwise_join; extern PGDLLIMPORT bool enable_partitionwise_aggregate; extern PGDLLIMPORT bool enable_parallel_append; extern PGDLLIMPORT bool enable_parallel_hash; +extern PGDLLIMPORT bool enable_partition_pruning; extern PGDLLIMPORT int constraint_exclusion; extern double clamp_row_est(double nrows); diff --git a/src/test/regress/expected/partition_prune.out b/src/test/regress/expected/partition_prune.out index 3e818edd339..e0cc5f3393a 100644 --- a/src/test/regress/expected/partition_prune.out +++ b/src/test/regress/expected/partition_prune.out @@ -2760,3 +2760,167 @@ explain (costs off) select * from pp_intrangepart where a = '(1,2)'::int4range; (2 rows) drop table pp_intrangepart; +-- +-- Ensure the enable_partition_prune GUC properly disables partition pruning. +-- +create table pp_lp (a int, value int) partition by list (a); +create table pp_lp1 partition of pp_lp for values in(1); +create table pp_lp2 partition of pp_lp for values in(2); +explain (costs off) select * from pp_lp where a = 1; + QUERY PLAN +-------------------------- + Append + -> Seq Scan on pp_lp1 + Filter: (a = 1) +(3 rows) + +explain (costs off) update pp_lp set value = 10 where a = 1; + QUERY PLAN +-------------------------- + Update on pp_lp + Update on pp_lp1 + -> Seq Scan on pp_lp1 + Filter: (a = 1) +(4 rows) + +explain (costs off) delete from pp_lp where a = 1; + QUERY PLAN +-------------------------- + Delete on pp_lp + Delete on pp_lp1 + -> Seq Scan on pp_lp1 + Filter: (a = 1) +(4 rows) + +set enable_partition_pruning = off; +set constraint_exclusion = 'partition'; -- this should not affect the result. +explain (costs off) select * from pp_lp where a = 1; + QUERY PLAN +-------------------------- + Append + -> Seq Scan on pp_lp1 + Filter: (a = 1) + -> Seq Scan on pp_lp2 + Filter: (a = 1) +(5 rows) + +explain (costs off) update pp_lp set value = 10 where a = 1; + QUERY PLAN +-------------------------- + Update on pp_lp + Update on pp_lp1 + Update on pp_lp2 + -> Seq Scan on pp_lp1 + Filter: (a = 1) + -> Seq Scan on pp_lp2 + Filter: (a = 1) +(7 rows) + +explain (costs off) delete from pp_lp where a = 1; + QUERY PLAN +-------------------------- + Delete on pp_lp + Delete on pp_lp1 + Delete on pp_lp2 + -> Seq Scan on pp_lp1 + Filter: (a = 1) + -> Seq Scan on pp_lp2 + Filter: (a = 1) +(7 rows) + +set constraint_exclusion = 'off'; -- this should not affect the result. +explain (costs off) select * from pp_lp where a = 1; + QUERY PLAN +-------------------------- + Append + -> Seq Scan on pp_lp1 + Filter: (a = 1) + -> Seq Scan on pp_lp2 + Filter: (a = 1) +(5 rows) + +explain (costs off) update pp_lp set value = 10 where a = 1; + QUERY PLAN +-------------------------- + Update on pp_lp + Update on pp_lp1 + Update on pp_lp2 + -> Seq Scan on pp_lp1 + Filter: (a = 1) + -> Seq Scan on pp_lp2 + Filter: (a = 1) +(7 rows) + +explain (costs off) delete from pp_lp where a = 1; + QUERY PLAN +-------------------------- + Delete on pp_lp + Delete on pp_lp1 + Delete on pp_lp2 + -> Seq Scan on pp_lp1 + Filter: (a = 1) + -> Seq Scan on pp_lp2 + Filter: (a = 1) +(7 rows) + +drop table pp_lp; +-- Ensure enable_partition_prune does not affect non-partitioned tables. +create table inh_lp (a int, value int); +create table inh_lp1 (a int, value int, check(a = 1)) inherits (inh_lp); +NOTICE: merging column "a" with inherited definition +NOTICE: merging column "value" with inherited definition +create table inh_lp2 (a int, value int, check(a = 2)) inherits (inh_lp); +NOTICE: merging column "a" with inherited definition +NOTICE: merging column "value" with inherited definition +set constraint_exclusion = 'partition'; +-- inh_lp2 should be removed in the following 3 cases. +explain (costs off) select * from inh_lp where a = 1; + QUERY PLAN +--------------------------- + Append + -> Seq Scan on inh_lp + Filter: (a = 1) + -> Seq Scan on inh_lp1 + Filter: (a = 1) +(5 rows) + +explain (costs off) update inh_lp set value = 10 where a = 1; + QUERY PLAN +--------------------------- + Update on inh_lp + Update on inh_lp + Update on inh_lp1 + -> Seq Scan on inh_lp + Filter: (a = 1) + -> Seq Scan on inh_lp1 + Filter: (a = 1) +(7 rows) + +explain (costs off) delete from inh_lp where a = 1; + QUERY PLAN +--------------------------- + Delete on inh_lp + Delete on inh_lp + Delete on inh_lp1 + -> Seq Scan on inh_lp + Filter: (a = 1) + -> Seq Scan on inh_lp1 + Filter: (a = 1) +(7 rows) + +-- Ensure we don't exclude normal relations when we only expect to exclude +-- inheritance children +explain (costs off) update inh_lp1 set value = 10 where a = 2; + QUERY PLAN +--------------------------- + Update on inh_lp1 + -> Seq Scan on inh_lp1 + Filter: (a = 2) +(3 rows) + +\set VERBOSITY terse \\ -- suppress cascade details +drop table inh_lp cascade; +NOTICE: drop cascades to 2 other objects +\set VERBOSITY default +reset enable_partition_pruning; +reset constraint_exclusion; diff --git a/src/test/regress/expected/sysviews.out b/src/test/regress/expected/sysviews.out index a19ee08749b..a1c90eb9057 100644 --- a/src/test/regress/expected/sysviews.out +++ b/src/test/regress/expected/sysviews.out @@ -83,12 +83,13 @@ select name, setting from pg_settings where name like 'enable%'; enable_nestloop | on enable_parallel_append | on enable_parallel_hash | on + enable_partition_pruning | on enable_partitionwise_aggregate | off enable_partitionwise_join | off enable_seqscan | on enable_sort | on enable_tidscan | on -(16 rows) +(17 rows) -- Test that the pg_timezone_names and pg_timezone_abbrevs views are -- more-or-less working. We can't test their contents in any great detail diff --git a/src/test/regress/sql/partition_prune.sql b/src/test/regress/sql/partition_prune.sql index d8d3e3c47db..6b7f57ab413 100644 --- a/src/test/regress/sql/partition_prune.sql +++ b/src/test/regress/sql/partition_prune.sql @@ -723,3 +723,55 @@ create table pp_intrangepart2inf partition of pp_intrangepart for values in ('[2 explain (costs off) select * from pp_intrangepart where a = '[1,2]'::int4range; explain (costs off) select * from pp_intrangepart where a = '(1,2)'::int4range; drop table pp_intrangepart; + +-- +-- Ensure the enable_partition_prune GUC properly disables partition pruning. +-- + +create table pp_lp (a int, value int) partition by list (a); +create table pp_lp1 partition of pp_lp for values in(1); +create table pp_lp2 partition of pp_lp for values in(2); + +explain (costs off) select * from pp_lp where a = 1; +explain (costs off) update pp_lp set value = 10 where a = 1; +explain (costs off) delete from pp_lp where a = 1; + +set enable_partition_pruning = off; + +set constraint_exclusion = 'partition'; -- this should not affect the result. + +explain (costs off) select * from pp_lp where a = 1; +explain (costs off) update pp_lp set value = 10 where a = 1; +explain (costs off) delete from pp_lp where a = 1; + +set constraint_exclusion = 'off'; -- this should not affect the result. + +explain (costs off) select * from pp_lp where a = 1; +explain (costs off) update pp_lp set value = 10 where a = 1; +explain (costs off) delete from pp_lp where a = 1; + +drop table pp_lp; + +-- Ensure enable_partition_prune does not affect non-partitioned tables. + +create table inh_lp (a int, value int); +create table inh_lp1 (a int, value int, check(a = 1)) inherits (inh_lp); +create table inh_lp2 (a int, value int, check(a = 2)) inherits (inh_lp); + +set constraint_exclusion = 'partition'; + +-- inh_lp2 should be removed in the following 3 cases. +explain (costs off) select * from inh_lp where a = 1; +explain (costs off) update inh_lp set value = 10 where a = 1; +explain (costs off) delete from inh_lp where a = 1; + +-- Ensure we don't exclude normal relations when we only expect to exclude +-- inheritance children +explain (costs off) update inh_lp1 set value = 10 where a = 2; + +\set VERBOSITY terse \\ -- suppress cascade details +drop table inh_lp cascade; +\set VERBOSITY default + +reset enable_partition_pruning; +reset constraint_exclusion;