diff --git a/doc/src/sgml/ddl.sgml b/doc/src/sgml/ddl.sgml index 3f3f567222..2152b4d16d 100644 --- a/doc/src/sgml/ddl.sgml +++ b/doc/src/sgml/ddl.sgml @@ -3759,7 +3759,151 @@ ANALYZE measurement; - + + Partition Pruning + + + partition pruning + + + + Partition pruning is a query optimization technique + that improves performance for partitioned tables. As an example: + + +SET enable_partition_pruning = on; -- the default +SELECT count(*) FROM measurement WHERE logdate >= DATE '2008-01-01'; + + + Without partition pruning, the above query would scan each of the + the partitions of the measurement table. With + partition pruning enabled, the planner will examine the definition of each + partition and prove that the partition need not + be scanned because it could not contain any rows meeting the query's + WHERE clause. When the planner can prove this, it + excludes the partition from the query plan. + + + + You can use the EXPLAIN command to show the difference + between a plan with enable_partition_pruning on and a plan + with it off. A typical unoptimized plan for this type of table setup is: + + +SET enable_partition_pruning = off; +EXPLAIN SELECT count(*) FROM measurement WHERE logdate >= DATE '2008-01-01'; + QUERY PLAN +─────────────────────────────────────────────────────────────────────────────────── + Aggregate (cost=188.76..188.77 rows=1 width=8) + -> Append (cost=0.00..181.05 rows=3085 width=0) + -> Seq Scan on measurement_y2006m02 (cost=0.00..33.12 rows=617 width=0) + Filter: (logdate >= '2008-01-01'::date) + -> Seq Scan on measurement_y2006m03 (cost=0.00..33.12 rows=617 width=0) + Filter: (logdate >= '2008-01-01'::date) + -> Seq Scan on measurement_y2007m11 (cost=0.00..33.12 rows=617 width=0) + Filter: (logdate >= '2008-01-01'::date) + -> Seq Scan on measurement_y2007m12 (cost=0.00..33.12 rows=617 width=0) + Filter: (logdate >= '2008-01-01'::date) + -> Seq Scan on measurement_y2008m01 (cost=0.00..33.12 rows=617 width=0) + Filter: (logdate >= '2008-01-01'::date) + + + Some or all of the partitions might use index scans instead of + full-table sequential scans, but the point here is that there + is no need to scan the older partitions at all to answer this query. + When we enable partition pruning, we get a significantly + cheaper plan that will deliver the same answer: + + +SET enable_partition_pruning = on; +EXPLAIN SELECT count(*) FROM measurement WHERE logdate >= DATE '2008-01-01'; + QUERY PLAN +─────────────────────────────────────────────────────────────────────────────────── + Aggregate (cost=37.75..37.76 rows=1 width=8) + -> Append (cost=0.00..36.21 rows=617 width=0) + -> Seq Scan on measurement_y2008m01 (cost=0.00..33.12 rows=617 width=0) + Filter: (logdate >= '2008-01-01'::date) + + + + + Note that partition pruning is driven only by the constraints defined by + the partition keys, not by the presence of indexes. Therefore it isn't + necessary to define indexes on the key columns. Whether an index + needs to be created for a given partition depends on whether you + expect that queries that scan the partition will generally scan + a large part of the partition or just a small part. An index will + be helpful in the latter case but not the former. + + + + Partition pruning + can be performed not only during the planning of a given query, but also + during its execution. This is useful as it can allow more partitions to + be pruned when clauses contain expressions whose values are unknown to the + query planner. For example, parameters defined in a + PREPARE statement, using a value obtained from a + subquery or using a parameterized value on the inner side of a nested loop + join. + Partition pruning during execution can be performed at any of the + following times: + + + + + During initialization of the query plan. Partition pruning can be + performed here for parameter values which are known during the + initialization phase of execution. Partitions which are pruned during + this stage will not show up in the query's EXPLAIN + or EXPLAIN ANALYZE. It is possible to determine the + number of partitions which were removed during this phase by observing + the Subplans Removed property in the + EXPLAIN output. + + + + + + During actual execution of the query plan. Partition pruning may also + be performed here to remove partitions using values which are only + known during actual query execution. This includes values from + subqueries and values from execution-time parameters such as those from + parameterized nested loop joins. Since the value of these parameters + may change many times during the execution of the query, partition + pruning is performed whenever one of the execution parameters being + used by partition pruning changes. Determining if partitions were + pruned during this phase requires careful inspection of the + nloops property in the + EXPLAIN ANALYZE output. + + + + + + + Partition pruning can be disabled using the + setting. + + + + + Currently, pruning of partitions during the planning of an + UPDATE or DELETE command is + implemented using the constraint exclusion method — see the + next section for details. However, it is still ruled by the + enable_partition_pruning setting instead of + constraint_exclusion. Also note that + partition pruning performed during execution is only done so for the + Append node type, not MergeAppend. + + + + Both of these limitations are likely to be removed in a future release + of PostgreSQL. + + + + Inheritance Partitioning and Constraint Exclusion @@ -3768,8 +3912,9 @@ ANALYZE measurement; Constraint exclusion is a query optimization technique - that improves performance for inheritance partitioned tables defined in the - fashion described above. As an example: + similar to partition pruning, used + for partitioned tables using the legacy inheritance method. + As an example similar to the one shown in the section above: SET constraint_exclusion = on; @@ -3893,95 +4038,8 @@ EXPLAIN SELECT count(*) FROM measurement WHERE logdate >= DATE '2008-01-01'; + - - - Declarative Partitioning and Partition Pruning - - - partition pruning - - - - Partition pruning is a query optimization technique - similar to constraint exclusion, but applies only to declaratively - partitioned tables. Like constraint exclusion, this uses (but is not - limited to using) the query's WHERE clause to exclude - partitions which cannot possibly contain any matching records. - - - - Partition pruning is much more efficient than constraint exclusion, since - it avoids scanning each partition's metadata to determine if the partition - is required for a particular query. - - - - Partition pruning is also more powerful than constraint exclusion as it - can be performed not only during the planning of a given query, but also - during its execution. This is useful as it can allow more partitions to - be pruned when clauses contain expressions whose values are unknown to the - query planner. For example, parameters defined in a - PREPARE statement, using a value obtained from a - subquery or using a parameterized value on the inner side of a nested loop - join. - - - - Partition pruning during execution can be performed at any of the - following times: - - - - - During initialization of the query plan. Partition pruning can be - performed here for parameter values which are known during the - initialization phase of execution. Partitions which are pruned during - this stage will not show up in the query's EXPLAIN - or EXPLAIN ANALYZE. It is possible to determine the - number of partitions which were removed during this phase by observing - the Subplans Removed property in the - EXPLAIN output. - - - - - - During actual execution of the query plan. Partition pruning may also - be performed here to remove partitions using values which are only - known during actual query execution. This includes values from - subqueries and values from execution-time parameters such as those from - parameterized nested loop joins. Since the value of these parameters - may change many times during the execution of the query, partition - pruning is performed whenever one of the execution parameters being - used by partition pruning changes. Determining if partitions were - pruned during this phase requires careful inspection of the - nloops property in the - EXPLAIN ANALYZE output. - - - - - - - Partition pruning can be disabled using the - setting. - - - - - Currently, pruning of partitions during the planning of an - UPDATE or DELETE command is - implemented using the constraint exclusion method. Only - SELECT uses the partition pruning technique. Also, - partition pruning performed during execution is only done so for the - Append node type. Both of these limitations are - likely to be removed in a future release of - PostgreSQL. - - - -