1EXPLAIN(7)               PostgreSQL 15.4 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           BUFFERS [ boolean ]
19           WAL [ boolean ]
20           TIMING [ boolean ]
21           SUMMARY [ boolean ]
22           FORMAT { TEXT | XML | JSON | YAML }
23

DESCRIPTION

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

PARAMETERS

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

OUTPUTS

159       The command's result is a textual description of the plan selected for
160       the statement, optionally annotated with execution statistics.
161       Section 14.1 describes the information provided.
162

NOTES

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

EXAMPLES

183       To show the plan for a simple query on a table with a single integer
184       column and 10000 rows:
185
186           EXPLAIN SELECT * FROM foo;
187
188                                  QUERY PLAN
189           ---------------------------------------------------------
190            Seq Scan on foo  (cost=0.00..155.00 rows=10000 width=4)
191           (1 row)
192
193       Here is the same query, with JSON output formatting:
194
195           EXPLAIN (FORMAT JSON) SELECT * FROM foo;
196                      QUERY PLAN
197           --------------------------------
198            [                             +
199              {                           +
200                "Plan": {                 +
201                  "Node Type": "Seq Scan",+
202                  "Relation Name": "foo", +
203                  "Alias": "foo",         +
204                  "Startup Cost": 0.00,   +
205                  "Total Cost": 155.00,   +
206                  "Plan Rows": 10000,     +
207                  "Plan Width": 4         +
208                }                         +
209              }                           +
210            ]
211           (1 row)
212
213       If there is an index and we use a query with an indexable WHERE
214       condition, EXPLAIN might show a different plan:
215
216           EXPLAIN SELECT * FROM foo WHERE i = 4;
217
218                                    QUERY PLAN
219           --------------------------------------------------------------
220            Index Scan using fi on foo  (cost=0.00..5.98 rows=1 width=4)
221              Index Cond: (i = 4)
222           (2 rows)
223
224       Here is the same query, but in YAML format:
225
226           EXPLAIN (FORMAT YAML) SELECT * FROM foo WHERE i='4';
227                     QUERY PLAN
228           -------------------------------
229            - Plan:                      +
230                Node Type: "Index Scan"  +
231                Scan Direction: "Forward"+
232                Index Name: "fi"         +
233                Relation Name: "foo"     +
234                Alias: "foo"             +
235                Startup Cost: 0.00       +
236                Total Cost: 5.98         +
237                Plan Rows: 1             +
238                Plan Width: 4            +
239                Index Cond: "(i = 4)"
240           (1 row)
241
242       XML format is left as an exercise for the reader.
243
244       Here is the same plan with cost estimates suppressed:
245
246           EXPLAIN (COSTS FALSE) SELECT * FROM foo WHERE i = 4;
247
248                   QUERY PLAN
249           ----------------------------
250            Index Scan using fi on foo
251              Index Cond: (i = 4)
252           (2 rows)
253
254       Here is an example of a query plan for a query using an aggregate
255       function:
256
257           EXPLAIN SELECT sum(i) FROM foo WHERE i < 10;
258
259                                        QUERY PLAN
260           ---------------------------------------------------------------------
261            Aggregate  (cost=23.93..23.93 rows=1 width=4)
262              ->  Index Scan using fi on foo  (cost=0.00..23.92 rows=6 width=4)
263                    Index Cond: (i < 10)
264           (3 rows)
265
266       Here is an example of using EXPLAIN EXECUTE to display the execution
267       plan for a prepared query:
268
269           PREPARE query(int, int) AS SELECT sum(bar) FROM test
270               WHERE id > $1 AND id < $2
271               GROUP BY foo;
272
273           EXPLAIN ANALYZE EXECUTE query(100, 200);
274
275                                                                  QUERY PLAN
276           ------------------------------------------------------------------------------------------------------------------------
277            HashAggregate  (cost=9.54..9.54 rows=1 width=8) (actual time=0.156..0.161 rows=11 loops=1)
278              Group Key: foo
279              ->  Index Scan using test_pkey on test  (cost=0.29..9.29 rows=50 width=8) (actual time=0.039..0.091 rows=99 loops=1)
280                    Index Cond: ((id > $1) AND (id < $2))
281            Planning time: 0.197 ms
282            Execution time: 0.225 ms
283           (6 rows)
284
285       Of course, the specific numbers shown here depend on the actual
286       contents of the tables involved. Also note that the numbers, and even
287       the selected query strategy, might vary between PostgreSQL releases due
288       to planner improvements. In addition, the ANALYZE command uses random
289       sampling to estimate data statistics; therefore, it is possible for
290       cost estimates to change after a fresh run of ANALYZE, even if the
291       actual distribution of data in the table has not changed.
292

COMPATIBILITY

294       There is no EXPLAIN statement defined in the SQL standard.
295

SEE ALSO

297       ANALYZE(7)
298
299
300
301PostgreSQL 15.4                      2023                           EXPLAIN(7)
Impressum