Examine the query plans of poorly performing queries to identify possible performance tuning opportunities.
Greenplum Database devises a query plan for each query. Choosing the right query plan to match the query and data structure is necessary for good performance. A query plan defines how Greenplum Database will run the query in the parallel execution environment.
The query optimizer uses data statistics maintained by the database to choose a query plan with the lowest possible cost. Cost is measured in disk I/O, shown as units of disk page fetches. The goal is to minimize the total execution cost for the plan.
View the plan for a given query with the EXPLAIN
command. EXPLAIN
shows the query optimizer's estimated cost for the query plan. For example:
EXPLAIN SELECT * FROM names WHERE id=22;
EXPLAIN ANALYZE
runs the statement in addition to displaying its plan. This is useful for determining how close the optimizer's estimates are to reality. For example:
EXPLAIN ANALYZE SELECT * FROM names WHERE id=22;
NoteIn Greenplum Database, the default GPORCA optimizer co-exists with the Postgres Planner. The EXPLAIN output generated by GPORCA is different than the output generated by the Postgres Planner.
By default, Greenplum Database uses GPORCA to generate an execution plan for a query when possible.
When the EXPLAIN ANALYZE
command uses GPORCA, the EXPLAIN
plan shows only the number of partitions that are being eliminated. The scanned partitions are not shown. To show name of the scanned partitions in the segment logs set the server configuration parameter gp_log_dynamic_partition_pruning
to on
. This example SET
command enables the parameter.
SET gp_log_dynamic_partition_pruning = on;
For information about GPORCA, see Querying Data.
Parent topic: Querying Data
A query plan is a tree of nodes. Each node in the plan represents a single operation, such as a table scan, join, aggregation, or sort.
Read plans from the bottom to the top: each node feeds rows into the node directly above it. The bottom nodes of a plan are usually table scan operations: sequential, index, or bitmap index scans. If the query requires joins, aggregations, sorts, or other operations on the rows, there are additional nodes above the scan nodes to perform these operations. The topmost plan nodes are usually Greenplum Database motion nodes: redistribute, explicit redistribute, broadcast, or gather motions. These operations move rows between segment instances during query processing.
The output of EXPLAIN
has one line for each node in the plan tree and shows the basic node type and the following execution cost estimates for that plan node:
cost —Measured in units of disk page fetches. 1.0 equals one sequential disk page read. The first estimate is the start-up cost of getting the first row and the second is the total cost of cost of getting all rows. The total cost assumes all rows will be retrieved, which is not always true; for example, if the query uses LIMIT
, not all rows are retrieved.
NoteThe cost values generated by GPORCA and the Postgres Planner are not directly comparable. The two optimizers use different cost models, as well as different algorithms, to determine the cost of an execution plan. Nothing can or should be inferred by comparing cost values between the two optimizers.
In addition, the cost generated for any given optimizer is valid only for comparing plan alternatives for a given single query and set of statistics. Different queries can generate plans with different costs, even when keeping the optimizer a constant.
To summarize, the cost is essentially an internal number used by a given optimizer, and nothing should be inferred by examining only the cost value displayed in the EXPLAIN
plans.
rows —The total number of rows output by this plan node. This number is usually less than the number of rows processed or scanned by the plan node, reflecting the estimated selectivity of any WHERE
clause conditions. Ideally, the estimate for the topmost node approximates the number of rows that the query actually returns, updates, or deletes.
width —The total bytes of all the rows that this plan node outputs.
Note the following:
The following example describes how to read an EXPLAIN
query plan for a query:
EXPLAIN SELECT * FROM names WHERE name = 'Joelle';
QUERY PLAN
------------------------------------------------------------
Gather Motion 2:1 (slice1) (cost=0.00..20.88 rows=1 width=13)
-> Seq Scan on 'names' (cost=0.00..20.88 rows=1 width=13)
Filter: name::text ~~ 'Joelle'::text
Read the plan from the bottom to the top. To start, the query optimizer sequentially scans the names table. Notice the WHERE
clause is applied as a filter condition. This means the scan operation checks the condition for each row it scans and outputs only the rows that satisfy the condition.
The results of the scan operation are passed to a gather motion operation. In Greenplum Database, a gather motion is when segments send rows to the master. In this example, we have two segment instances that send to one master instance. This operation is working on slice1
of the parallel query execution plan. A query plan is divided into slices so the segments can work on portions of the query plan in parallel.
The estimated startup cost for this plan is 00.00
(no cost) and a total cost of 20.88
disk page fetches. The optimizer estimates this query will return one row.
EXPLAIN ANALYZE
plans and runs the statement. The EXPLAIN ANALYZE
plan shows the actual execution cost along with the optimizer's estimates. This allows you to see if the optimizer's estimates are close to reality. EXPLAIN ANALYZE
also shows the following:
The total runtime (in milliseconds) in which the query ran.
The memory used by each slice of the query plan, as well as the memory reserved for the whole query statement.
The number of workers (segments) involved in a plan node operation. Only segments that return rows are counted.
The maximum number of rows returned by the segment that produced the most rows for the operation. If multiple segments produce an equal number of rows, EXPLAIN ANALYZE
shows the segment with the longest <time> to end.
The segment id of the segment that produced the most rows for an operation.
For relevant operations, the amount of memory (work_mem
) used by the operation. If the work_mem
was insufficient to perform the operation in memory, the plan shows the amount of data spilled to disk for the lowest-performing segment. For example:
Work_mem used: 64K bytes avg, 64K bytes max (seg0).
Work_mem wanted: 90K bytes avg, 90K byes max (seg0) to lessen
workfile I/O affecting 2 workers.
The time (in milliseconds) in which the segment that produced the most rows retrieved the first row, and the time taken for that segment to retrieve all rows. The result may omit <time> to first row if it is the same as the <time> to end.
This example describes how to read an EXPLAIN ANALYZE
query plan using the same query. The bold
parts of the plan show actual timing and rows returned for each plan node, as well as memory and time statistics for the whole query.
EXPLAIN ANALYZE SELECT * FROM names WHERE name = 'Joelle';
QUERY PLAN
------------------------------------------------------------
Gather Motion 2:1 (slice1; segments: 2) (cost=0.00..20.88 rows=1 width=13)
Rows out: 1 rows at destination with 0.305 ms to first row, 0.537 ms to end, start offset by 0.289 ms.
-> Seq Scan on names (cost=0.00..20.88 rows=1 width=13)
Rows out: Avg 1 rows x 2 workers. Max 1 rows (seg0) with 0.255 ms to first row, 0.486 ms to end, start offset by 0.968 ms.
Filter: name = 'Joelle'::text
Slice statistics:
(slice0) Executor memory: 135K bytes.
(slice1) Executor memory: 151K bytes avg x 2 workers, 151K bytes max (seg0).
Statement statistics:
Memory used: 128000K bytes
Total runtime: 22.548 ms
Read the plan from the bottom to the top. The total elapsed time to run this query was 22.548 milliseconds.
The sequential scan operation had only one segment (seg0) that returned rows, and it returned just 1 row. It took 0.255 milliseconds to find the first row and 0.486 to scan all rows. This result is close to the optimizer's estimate: the query optimizer estimated it would return one row for this query. The gather motion (segments sending data to the master) received 1 row . The total elapsed time for this operation was 0.537 milliseconds.
You can view EXPLAIN output to determine if GPORCA is enabled for the query plan and whether GPORCA or the Postgres Planner generated the explain plan. The information appears at the end of the EXPLAIN output. The Settings
line displays the setting of the server configuration parameter OPTIMIZER
. The Optimizer status
line displays whether GPORCA or the Postgres Planner generated the explain plan.
For these two example query plans, GPORCA is enabled, the server configuration parameter OPTIMIZER
is on
. For the first plan, GPORCA generated the EXPLAIN plan. For the second plan, Greenplum Database fell back to the Postgres Planner to generate the query plan.
QUERY PLAN
------------------------------------------------------------------------------------
Aggregate (cost=0.00..296.14 rows=1 width=8)
-> Gather Motion 2:1 (slice1; segments: 2) (cost=0.00..295.10 rows=1 width=8)
-> Aggregate (cost=0.00..294.10 rows=1 width=8)
-> Seq Scan on part (cost=0.00..97.69 rows=100040 width=1)
Settings: optimizer=on
Optimizer status: Pivotal Optimizer (GPORCA) version 1.584
(5 rows)
explain select count(*) from part;
QUERY PLAN
----------------------------------------------------------------------------------------
Aggregate (cost=3519.05..3519.06 rows=1 width=8)
-> Gather Motion 2:1 (slice1; segments: 2) (cost=3518.99..3519.03 rows=1 width=8)
-> Aggregate (cost=3518.99..3519.00 rows=1 width=8)
-> Seq Scan on part (cost=0.00..3018.79 rows=100040 width=1)
Settings: optimizer=on
Optimizer status: Postgres query optimizer
(5 rows)
For this query, the server configuration parameter OPTIMIZER
is off
.
explain select count(*) from part;
QUERY PLAN
----------------------------------------------------------------------------------------
Aggregate (cost=3519.05..3519.06 rows=1 width=8)
-> Gather Motion 2:1 (slice1; segments: 2) (cost=3518.99..3519.03 rows=1 width=8)
-> Aggregate (cost=3518.99..3519.00 rows=1 width=8)
-> Seq Scan on part (cost=0.00..3018.79 rows=100040 width=1)
Settings: optimizer=off
Optimizer status: Postgres query optimizer
(5 rows)
If a query performs poorly, examine its query plan and ask the following questions:
Do operations in the plan take an exceptionally long time? Look for an operation consumes the majority of query processing time. For example, if an index scan takes longer than expected, the index could be out-of-date and need to be reindexed. Or, adjust enable_<operator>
parameters to see if you can force the Postgres Planner to choose a different plan by deactivating a particular query plan operator for that query.
Does the query planning time exceed query execution time? When the query involves many table joins, the Postgres Planner uses a dynamic algorithm to plan the query that is in part based on the number of table joins. You can reduce the amount of time that the Postgres Planner spends planning the query by setting the join_collapse_limit
and from_collapse_limit
server configuration parameters to a smaller value, such as 8
. Note that while smaller values reduce planning time, they may also yield inferior query plans.
Are the optimizer's estimates close to reality? Run EXPLAIN ANALYZE
and see if the number of rows the optimizer estimates is close to the number of rows the query operation actually returns. If there is a large discrepancy, collect more statistics on the relevant columns.
See the Greenplum Database Reference Guide for more information on the EXPLAIN ANALYZE
and ANALYZE
commands.
Are selective predicates applied early in the plan? Apply the most selective filters early in the plan so fewer rows move up the plan tree. If the query plan does not correctly estimate query predicate selectivity, collect more statistics on the relevant columns. See the ANALYZE
command in the Greenplum Database Reference Guide for more information collecting statistics.You can also try reordering the WHERE
clause of your SQL statement.
Does the optimizer choose the best join order? When you have a query that joins multiple tables, make sure that the optimizer chooses the most selective join order. Joins that eliminate the largest number of rows should be done earlier in the plan so fewer rows move up the plan tree.
If the plan is not choosing the optimal join order, set join_collapse_limit=1
and use explicit JOIN
syntax in your SQL statement to force the Postgres Planner to the specified join order. You can also collect more statistics on the relevant join columns.
See the ANALYZE
command in the Greenplum Database Reference Guide for more information collecting statistics.
Does the optimizer selectively scan partitioned tables? If you use table partitioning, is the optimizer selectively scanning only the child tables required to satisfy the query predicates? Scans of the parent tables should return 0 rows since the parent tables do not contain any data. See Verifying Your Partition Strategy for an example of a query plan that shows a selective partition scan.
Does the optimizer choose hash aggregate and hash join operations where applicable? Hash operations are typically much faster than other types of joins or aggregations. Row comparison and sorting is done in memory rather than reading/writing from disk. To enable the query optimizer to choose hash operations, there must be sufficient memory available to hold the estimated number of rows. Try increasing work memory to improve performance for a query. If possible, run an EXPLAIN ANALYZE
for the query to show which plan operations spilled to disk, how much work memory they used, and how much memory was required to avoid spilling to disk. For example:
Work_mem used: 23430K bytes avg, 23430K bytes max (seg0). Work_mem wanted: 33649K bytes avg, 33649K bytes max (seg0) to lessen workfile I/O affecting 2 workers.
The "bytes wanted" message from EXPLAIN ANALYZE
is based on the amount of data written to work files and is not exact. The minimum work_mem
needed can differ from the suggested value.