1EXPLAIN(7)               PostgreSQL 16.1 Documentation              EXPLAIN(7)
2
3
4

NAME

6       EXPLAIN - show the execution plan of a statement
7

SYNOPSIS

9       EXPLAIN [ ( option [, ...] ) ] statement
10       EXPLAIN [ ANALYZE ] [ VERBOSE ] statement
11
12       where option can be one of:
13
14           ANALYZE [ boolean ]
15           VERBOSE [ boolean ]
16           COSTS [ boolean ]
17           SETTINGS [ boolean ]
18           GENERIC_PLAN [ boolean ]
19           BUFFERS [ boolean ]
20           WAL [ boolean ]
21           TIMING [ boolean ]
22           SUMMARY [ boolean ]
23           FORMAT { TEXT | XML | JSON | YAML }
24

DESCRIPTION

26       This command displays the execution plan that the PostgreSQL planner
27       generates for the supplied statement. The execution plan shows how the
28       table(s) referenced by the statement will be scanned — by plain
29       sequential scan, index scan, etc. — and if multiple tables are
30       referenced, what join algorithms will be used to bring together the
31       required rows from each input table.
32
33       The most critical part of the display is the estimated statement
34       execution cost, which is the planner's guess at how long it will take
35       to run the statement (measured in cost units that are arbitrary, but
36       conventionally mean disk page fetches). Actually two numbers are shown:
37       the start-up cost before the first row can be returned, and the total
38       cost to return all the rows. For most queries the total cost is what
39       matters, but in contexts such as a subquery in EXISTS, the planner will
40       choose the smallest start-up cost instead of the smallest total cost
41       (since the executor will stop after getting one row, anyway). Also, if
42       you limit the number of rows to return with a LIMIT clause, the planner
43       makes an appropriate interpolation between the endpoint costs to
44       estimate which plan is really the cheapest.
45
46       The ANALYZE option causes the statement to be actually executed, not
47       only planned. Then actual run time statistics are added to the display,
48       including the total elapsed time expended within each plan node (in
49       milliseconds) and the total number of rows it actually returned. This
50       is useful for seeing whether the planner's estimates are close to
51       reality.
52
53           Important
54           Keep in mind that the statement is actually executed when the
55           ANALYZE option is used. Although EXPLAIN will discard any output
56           that a SELECT would return, other side effects of the statement
57           will happen as usual. If you wish to use EXPLAIN ANALYZE on an
58           INSERT, UPDATE, DELETE, MERGE, CREATE TABLE AS, or EXECUTE
59           statement without letting the command affect your data, use this
60           approach:
61
62               BEGIN;
63               EXPLAIN ANALYZE ...;
64               ROLLBACK;
65
66       Only the ANALYZE and VERBOSE options can be specified, and only in that
67       order, without surrounding the option list in parentheses. Prior to
68       PostgreSQL 9.0, the unparenthesized syntax was the only one supported.
69       It is expected that all new options will be supported only in the
70       parenthesized syntax.
71

PARAMETERS

73       ANALYZE
74           Carry out the command and show actual run times and other
75           statistics. This parameter defaults to FALSE.
76
77       VERBOSE
78           Display additional information regarding the plan. Specifically,
79           include the output column list for each node in the plan tree,
80           schema-qualify table and function names, always label variables in
81           expressions with their range table alias, and always print the name
82           of each trigger for which statistics are displayed. The query
83           identifier will also be displayed if one has been computed, see
84           compute_query_id for more details. This parameter defaults to
85           FALSE.
86
87       COSTS
88           Include information on the estimated startup and total cost of each
89           plan node, as well as the estimated number of rows and the
90           estimated width of each row. This parameter defaults to TRUE.
91
92       SETTINGS
93           Include information on configuration parameters. Specifically,
94           include options affecting query planning with value different from
95           the built-in default value. This parameter defaults to FALSE.
96
97       GENERIC_PLAN
98           Allow the statement to contain parameter placeholders like $1, and
99           generate a generic plan that does not depend on the values of those
100           parameters. See PREPARE for details about generic plans and the
101           types of statement that support parameters. This parameter cannot
102           be used together with ANALYZE. It defaults to FALSE.
103
104       BUFFERS
105           Include information on buffer usage. Specifically, include the
106           number of shared blocks hit, read, dirtied, and written, the number
107           of local blocks hit, read, dirtied, and written, the number of temp
108           blocks read and written, and the time spent reading and writing
109           data file blocks and temporary file blocks (in milliseconds) if
110           track_io_timing is enabled. A hit means that a read was avoided
111           because the block was found already in cache when needed. Shared
112           blocks contain data from regular tables and indexes; local blocks
113           contain data from temporary tables and indexes; while temporary
114           blocks contain short-term working data used in sorts, hashes,
115           Materialize plan nodes, and similar cases. The number of blocks
116           dirtied indicates the number of previously unmodified blocks that
117           were changed by this query; while the number of blocks written
118           indicates the number of previously-dirtied blocks evicted from
119           cache by this backend during query processing. The number of blocks
120           shown for an upper-level node includes those used by all its child
121           nodes. In text format, only non-zero values are printed. This
122           parameter defaults to FALSE.
123
124       WAL
125           Include information on WAL record generation. Specifically, include
126           the number of records, number of full page images (fpi) and the
127           amount of WAL generated in bytes. In text format, only non-zero
128           values are printed. This parameter may only be used when ANALYZE is
129           also enabled. It defaults to FALSE.
130
131       TIMING
132           Include actual startup time and time spent in each node in the
133           output. The overhead of repeatedly reading the system clock can
134           slow down the query significantly on some systems, so it may be
135           useful to set this parameter to FALSE when only actual row counts,
136           and not exact times, are needed. Run time of the entire statement
137           is always measured, even when node-level timing is turned off with
138           this option. This parameter may only be used when ANALYZE is also
139           enabled. It defaults to TRUE.
140
141       SUMMARY
142           Include summary information (e.g., totaled timing information)
143           after the query plan. Summary information is included by default
144           when ANALYZE is used but otherwise is not included by default, but
145           can be enabled using this option. Planning time in EXPLAIN EXECUTE
146           includes the time required to fetch the plan from the cache and the
147           time required for re-planning, if necessary.
148
149       FORMAT
150           Specify the output format, which can be TEXT, XML, JSON, or YAML.
151           Non-text output contains the same information as the text output
152           format, but is easier for programs to parse. This parameter
153           defaults to TEXT.
154
155       boolean
156           Specifies whether the selected option should be turned on or off.
157           You can write TRUE, ON, or 1 to enable the option, and FALSE, OFF,
158           or 0 to disable it. The boolean value can also be omitted, in which
159           case TRUE is assumed.
160
161       statement
162           Any SELECT, INSERT, UPDATE, DELETE, MERGE, VALUES, EXECUTE,
163           DECLARE, CREATE TABLE AS, or CREATE MATERIALIZED VIEW AS statement,
164           whose execution plan you wish to see.
165

OUTPUTS

167       The command's result is a textual description of the plan selected for
168       the statement, optionally annotated with execution statistics.
169       Section 14.1 describes the information provided.
170

NOTES

172       In order to allow the PostgreSQL query planner to make reasonably
173       informed decisions when optimizing queries, the pg_statistic data
174       should be up-to-date for all tables used in the query. Normally the
175       autovacuum daemon will take care of that automatically. But if a table
176       has recently had substantial changes in its contents, you might need to
177       do a manual ANALYZE rather than wait for autovacuum to catch up with
178       the changes.
179
180       In order to measure the run-time cost of each node in the execution
181       plan, the current implementation of EXPLAIN ANALYZE adds profiling
182       overhead to query execution. As a result, running EXPLAIN ANALYZE on a
183       query can sometimes take significantly longer than executing the query
184       normally. The amount of overhead depends on the nature of the query, as
185       well as the platform being used. The worst case occurs for plan nodes
186       that in themselves require very little time per execution, and on
187       machines that have relatively slow operating system calls for obtaining
188       the time of day.
189

EXAMPLES

191       To show the plan for a simple query on a table with a single integer
192       column and 10000 rows:
193
194           EXPLAIN SELECT * FROM foo;
195
196                                  QUERY PLAN
197           ---------------------------------------------------------
198            Seq Scan on foo  (cost=0.00..155.00 rows=10000 width=4)
199           (1 row)
200
201       Here is the same query, with JSON output formatting:
202
203           EXPLAIN (FORMAT JSON) SELECT * FROM foo;
204                      QUERY PLAN
205           --------------------------------
206            [                             +
207              {                           +
208                "Plan": {                 +
209                  "Node Type": "Seq Scan",+
210                  "Relation Name": "foo", +
211                  "Alias": "foo",         +
212                  "Startup Cost": 0.00,   +
213                  "Total Cost": 155.00,   +
214                  "Plan Rows": 10000,     +
215                  "Plan Width": 4         +
216                }                         +
217              }                           +
218            ]
219           (1 row)
220
221       If there is an index and we use a query with an indexable WHERE
222       condition, EXPLAIN might show a different plan:
223
224           EXPLAIN SELECT * FROM foo WHERE i = 4;
225
226                                    QUERY PLAN
227           --------------------------------------------------------------
228            Index Scan using fi on foo  (cost=0.00..5.98 rows=1 width=4)
229              Index Cond: (i = 4)
230           (2 rows)
231
232       Here is the same query, but in YAML format:
233
234           EXPLAIN (FORMAT YAML) SELECT * FROM foo WHERE i='4';
235                     QUERY PLAN
236           -------------------------------
237            - Plan:                      +
238                Node Type: "Index Scan"  +
239                Scan Direction: "Forward"+
240                Index Name: "fi"         +
241                Relation Name: "foo"     +
242                Alias: "foo"             +
243                Startup Cost: 0.00       +
244                Total Cost: 5.98         +
245                Plan Rows: 1             +
246                Plan Width: 4            +
247                Index Cond: "(i = 4)"
248           (1 row)
249
250       XML format is left as an exercise for the reader.
251
252       Here is the same plan with cost estimates suppressed:
253
254           EXPLAIN (COSTS FALSE) SELECT * FROM foo WHERE i = 4;
255
256                   QUERY PLAN
257           ----------------------------
258            Index Scan using fi on foo
259              Index Cond: (i = 4)
260           (2 rows)
261
262       Here is an example of a query plan for a query using an aggregate
263       function:
264
265           EXPLAIN SELECT sum(i) FROM foo WHERE i < 10;
266
267                                        QUERY PLAN
268           ---------------------------------------------------------------------
269            Aggregate  (cost=23.93..23.93 rows=1 width=4)
270              ->  Index Scan using fi on foo  (cost=0.00..23.92 rows=6 width=4)
271                    Index Cond: (i < 10)
272           (3 rows)
273
274       Here is an example of using EXPLAIN EXECUTE to display the execution
275       plan for a prepared query:
276
277           PREPARE query(int, int) AS SELECT sum(bar) FROM test
278               WHERE id > $1 AND id < $2
279               GROUP BY foo;
280
281           EXPLAIN ANALYZE EXECUTE query(100, 200);
282
283                                                                  QUERY PLAN
284           -------------------------------------------------------------------------------------------------------------------------
285            HashAggregate  (cost=10.77..10.87 rows=10 width=12) (actual time=0.043..0.044 rows=10 loops=1)
286              Group Key: foo
287              Batches: 1  Memory Usage: 24kB
288              ->  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)
289                    Index Cond: ((id > 100) AND (id < 200))
290            Planning Time: 0.244 ms
291            Execution Time: 0.073 ms
292           (7 rows)
293
294       Of course, the specific numbers shown here depend on the actual
295       contents of the tables involved. Also note that the numbers, and even
296       the selected query strategy, might vary between PostgreSQL releases due
297       to planner improvements. In addition, the ANALYZE command uses random
298       sampling to estimate data statistics; therefore, it is possible for
299       cost estimates to change after a fresh run of ANALYZE, even if the
300       actual distribution of data in the table has not changed.
301
302       Notice that the previous example showed a “custom” plan for the
303       specific parameter values given in EXECUTE. We might also wish to see
304       the generic plan for a parameterized query, which can be done with
305       GENERIC_PLAN:
306
307           EXPLAIN (GENERIC_PLAN)
308             SELECT sum(bar) FROM test
309               WHERE id > $1 AND id < $2
310               GROUP BY foo;
311
312                                             QUERY PLAN
313           -------------------------------------------------------------------------------
314            HashAggregate  (cost=26.79..26.89 rows=10 width=12)
315              Group Key: foo
316              ->  Index Scan using test_pkey on test  (cost=0.29..24.29 rows=500 width=8)
317                    Index Cond: ((id > $1) AND (id < $2))
318           (4 rows)
319
320       In this case the parser correctly inferred that $1 and $2 should have
321       the same data type as id, so the lack of parameter type information
322       from PREPARE was not a problem. In other cases it might be necessary to
323       explicitly specify types for the parameter symbols, which can be done
324       by casting them, for example:
325
326           EXPLAIN (GENERIC_PLAN)
327             SELECT sum(bar) FROM test
328               WHERE id > $1::integer AND id < $2::integer
329               GROUP BY foo;
330
331

COMPATIBILITY

333       There is no EXPLAIN statement defined in the SQL standard.
334

SEE ALSO

336       ANALYZE(7)
337
338
339
340PostgreSQL 16.1                      2023                           EXPLAIN(7)
Impressum