table of contents
EXPLAIN(7) | PostgreSQL 17.0 Documentation | EXPLAIN(7) |
NAME¶
EXPLAIN - show the execution plan of a statement
SYNOPSIS¶
EXPLAIN [ ( option [, ...] ) ] statement where option can be one of:
ANALYZE [ boolean ]
VERBOSE [ boolean ]
COSTS [ boolean ]
SETTINGS [ boolean ]
GENERIC_PLAN [ boolean ]
BUFFERS [ boolean ]
SERIALIZE [ { NONE | TEXT | BINARY } ]
WAL [ boolean ]
TIMING [ boolean ]
SUMMARY [ boolean ]
MEMORY [ boolean ]
FORMAT { TEXT | XML | JSON | YAML }
DESCRIPTION¶
This command displays the execution plan that the PostgreSQL planner generates for the supplied statement. The execution plan shows how the table(s) referenced by the statement will be scanned — by plain sequential scan, index scan, etc. — and if multiple tables are referenced, what join algorithms will be used to bring together the required rows from each input table.
The most critical part of the display is the estimated statement execution cost, which is the planner's guess at how long it will take to run the statement (measured in cost units that are arbitrary, but conventionally mean disk page fetches). Actually two numbers are shown: the start-up cost before the first row can be returned, and the total cost to return all the rows. For most queries the total cost is what matters, but in contexts such as a subquery in EXISTS, the planner will choose the smallest start-up cost instead of the smallest total cost (since the executor will stop after getting one row, anyway). Also, if you limit the number of rows to return with a LIMIT clause, the planner makes an appropriate interpolation between the endpoint costs to estimate which plan is really the cheapest.
The ANALYZE option causes the statement to be actually executed, not only planned. Then actual run time statistics are added to the display, including the total elapsed time expended within each plan node (in milliseconds) and the total number of rows it actually returned. This is useful for seeing whether the planner's estimates are close to reality.
Important
Keep in mind that the statement is actually executed when the ANALYZE option is used. Although EXPLAIN will discard any output that a SELECT would return, other side effects of the statement will happen as usual. If you wish to use EXPLAIN ANALYZE on an INSERT, UPDATE, DELETE, MERGE, CREATE TABLE AS, or EXECUTE statement without letting the command affect your data, use this approach:
BEGIN; EXPLAIN ANALYZE ...; ROLLBACK;
PARAMETERS¶
ANALYZE
VERBOSE
COSTS
SETTINGS
GENERIC_PLAN
BUFFERS
SERIALIZE
WAL
TIMING
SUMMARY
MEMORY
FORMAT
boolean
statement
OUTPUTS¶
The command's result is a textual description of the plan selected for the statement, optionally annotated with execution statistics. Section 14.1 describes the information provided.
NOTES¶
In order to allow the PostgreSQL query planner to make reasonably informed decisions when optimizing queries, the pg_statistic data should be up-to-date for all tables used in the query. Normally the autovacuum daemon will take care of that automatically. But if a table has recently had substantial changes in its contents, you might need to do a manual ANALYZE rather than wait for autovacuum to catch up with the changes.
In order to measure the run-time cost of each node in the execution plan, the current implementation of EXPLAIN ANALYZE adds profiling overhead to query execution. As a result, running EXPLAIN ANALYZE on a query can sometimes take significantly longer than executing the query normally. The amount of overhead depends on the nature of the query, as well as the platform being used. The worst case occurs for plan nodes that in themselves require very little time per execution, and on machines that have relatively slow operating system calls for obtaining the time of day.
EXAMPLES¶
To show the plan for a simple query on a table with a single integer column and 10000 rows:
EXPLAIN SELECT * FROM foo;
QUERY PLAN ---------------------------------------------------------
Seq Scan on foo (cost=0.00..155.00 rows=10000 width=4) (1 row)
Here is the same query, with JSON output formatting:
EXPLAIN (FORMAT JSON) SELECT * FROM foo;
QUERY PLAN --------------------------------
[ +
{ +
"Plan": { +
"Node Type": "Seq Scan",+
"Relation Name": "foo", +
"Alias": "foo", +
"Startup Cost": 0.00, +
"Total Cost": 155.00, +
"Plan Rows": 10000, +
"Plan Width": 4 +
} +
} +
] (1 row)
If there is an index and we use a query with an indexable WHERE condition, EXPLAIN might show a different plan:
EXPLAIN SELECT * FROM foo WHERE i = 4;
QUERY PLAN --------------------------------------------------------------
Index Scan using fi on foo (cost=0.00..5.98 rows=1 width=4)
Index Cond: (i = 4) (2 rows)
Here is the same query, but in YAML format:
EXPLAIN (FORMAT YAML) SELECT * FROM foo WHERE i='4';
QUERY PLAN -------------------------------
- Plan: +
Node Type: "Index Scan" +
Scan Direction: "Forward"+
Index Name: "fi" +
Relation Name: "foo" +
Alias: "foo" +
Startup Cost: 0.00 +
Total Cost: 5.98 +
Plan Rows: 1 +
Plan Width: 4 +
Index Cond: "(i = 4)" (1 row)
XML format is left as an exercise for the reader.
Here is the same plan with cost estimates suppressed:
EXPLAIN (COSTS FALSE) SELECT * FROM foo WHERE i = 4;
QUERY PLAN ----------------------------
Index Scan using fi on foo
Index Cond: (i = 4) (2 rows)
Here is an example of a query plan for a query using an aggregate function:
EXPLAIN SELECT sum(i) FROM foo WHERE i < 10;
QUERY PLAN ---------------------------------------------------------------------
Aggregate (cost=23.93..23.93 rows=1 width=4)
-> Index Scan using fi on foo (cost=0.00..23.92 rows=6 width=4)
Index Cond: (i < 10) (3 rows)
Here is an example of using EXPLAIN EXECUTE to display the execution plan for a prepared query:
PREPARE query(int, int) AS SELECT sum(bar) FROM test
WHERE id > $1 AND id < $2
GROUP BY foo; EXPLAIN ANALYZE EXECUTE query(100, 200);
QUERY PLAN -------------------------------------------------------------------------------------------------------------------------
HashAggregate (cost=10.77..10.87 rows=10 width=12) (actual time=0.043..0.044 rows=10 loops=1)
Group Key: foo
Batches: 1 Memory Usage: 24kB
-> Index Scan using test_pkey on test (cost=0.29..10.27 rows=99 width=8) (actual time=0.009..0.025 rows=99 loops=1)
Index Cond: ((id > 100) AND (id < 200))
Planning Time: 0.244 ms
Execution Time: 0.073 ms (7 rows)
Of course, the specific numbers shown here depend on the actual contents of the tables involved. Also note that the numbers, and even the selected query strategy, might vary between PostgreSQL releases due to planner improvements. In addition, the ANALYZE command uses random sampling to estimate data statistics; therefore, it is possible for cost estimates to change after a fresh run of ANALYZE, even if the actual distribution of data in the table has not changed.
Notice that the previous example showed a “custom” plan for the specific parameter values given in EXECUTE. We might also wish to see the generic plan for a parameterized query, which can be done with GENERIC_PLAN:
EXPLAIN (GENERIC_PLAN)
SELECT sum(bar) FROM test
WHERE id > $1 AND id < $2
GROUP BY foo;
QUERY PLAN -------------------------------------------------------------------------------
HashAggregate (cost=26.79..26.89 rows=10 width=12)
Group Key: foo
-> Index Scan using test_pkey on test (cost=0.29..24.29 rows=500 width=8)
Index Cond: ((id > $1) AND (id < $2)) (4 rows)
In this case the parser correctly inferred that $1 and $2 should have the same data type as id, so the lack of parameter type information from PREPARE was not a problem. In other cases it might be necessary to explicitly specify types for the parameter symbols, which can be done by casting them, for example:
EXPLAIN (GENERIC_PLAN)
SELECT sum(bar) FROM test
WHERE id > $1::integer AND id < $2::integer
GROUP BY foo;
COMPATIBILITY¶
There is no EXPLAIN statement defined in the SQL standard.
The following syntax was used before PostgreSQL version 9.0 and is still supported:
EXPLAIN [ ANALYZE ] [ VERBOSE ] statement
Note that in this syntax, the options must be specified in exactly the order shown.
SEE ALSO¶
2024 | PostgreSQL 17.0 |