1EXPLAIN(7) PostgreSQL 13.4 Documentation EXPLAIN(7)
2
3
4
6 EXPLAIN - show the execution plan of a statement
7
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
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, CREATE TABLE AS, or EXECUTE statement
58 without letting the command affect your data, use this approach:
59
60 BEGIN;
61 EXPLAIN ANALYZE ...;
62 ROLLBACK;
63
64 Only the ANALYZE and VERBOSE options can be specified, and only in that
65 order, without surrounding the option list in parentheses. Prior to
66 PostgreSQL 9.0, the unparenthesized syntax was the only one supported.
67 It is expected that all new options will be supported only in the
68 parenthesized syntax.
69
71 ANALYZE
72 Carry out the command and show actual run times and other
73 statistics. This parameter defaults to FALSE.
74
75 VERBOSE
76 Display additional information regarding the plan. Specifically,
77 include the output column list for each node in the plan tree,
78 schema-qualify table and function names, always label variables in
79 expressions with their range table alias, and always print the name
80 of each trigger for which statistics are displayed. This parameter
81 defaults to FALSE.
82
83 COSTS
84 Include information on the estimated startup and total cost of each
85 plan node, as well as the estimated number of rows and the
86 estimated width of each row. This parameter defaults to TRUE.
87
88 SETTINGS
89 Include information on configuration parameters. Specifically,
90 include options affecting query planning with value different from
91 the built-in default value. This parameter defaults to FALSE.
92
93 BUFFERS
94 Include information on buffer usage. Specifically, include the
95 number of shared blocks hit, read, dirtied, and written, the number
96 of local blocks hit, read, dirtied, and written, the number of temp
97 blocks read and written, and the time spent reading and writing
98 data file blocks (in milliseconds) if track_io_timing is enabled. A
99 hit means that a read was avoided because the block was found
100 already in cache when needed. Shared blocks contain data from
101 regular tables and indexes; local blocks contain data from
102 temporary tables and indexes; while temp blocks contain short-term
103 working data used in sorts, hashes, Materialize plan nodes, and
104 similar cases. The number of blocks dirtied indicates the number of
105 previously unmodified blocks that were changed by this query; while
106 the number of blocks written indicates the number of
107 previously-dirtied blocks evicted from cache by this backend during
108 query processing. The number of blocks shown for an upper-level
109 node includes those used by all its child nodes. In text format,
110 only non-zero values are printed. It defaults to FALSE.
111
112 WAL
113 Include information on WAL record generation. Specifically, include
114 the number of records, number of full page images (fpi) and the
115 amount of WAL generated in bytes. In text format, only non-zero
116 values are printed. This parameter may only be used when ANALYZE is
117 also enabled. It defaults to FALSE.
118
119 TIMING
120 Include actual startup time and time spent in each node in the
121 output. The overhead of repeatedly reading the system clock can
122 slow down the query significantly on some systems, so it may be
123 useful to set this parameter to FALSE when only actual row counts,
124 and not exact times, are needed. Run time of the entire statement
125 is always measured, even when node-level timing is turned off with
126 this option. This parameter may only be used when ANALYZE is also
127 enabled. It defaults to TRUE.
128
129 SUMMARY
130 Include summary information (e.g., totaled timing information)
131 after the query plan. Summary information is included by default
132 when ANALYZE is used but otherwise is not included by default, but
133 can be enabled using this option. Planning time in EXPLAIN EXECUTE
134 includes the time required to fetch the plan from the cache and the
135 time required for re-planning, if necessary.
136
137 FORMAT
138 Specify the output format, which can be TEXT, XML, JSON, or YAML.
139 Non-text output contains the same information as the text output
140 format, but is easier for programs to parse. This parameter
141 defaults to TEXT.
142
143 boolean
144 Specifies whether the selected option should be turned on or off.
145 You can write TRUE, ON, or 1 to enable the option, and FALSE, OFF,
146 or 0 to disable it. The boolean value can also be omitted, in which
147 case TRUE is assumed.
148
149 statement
150 Any SELECT, INSERT, UPDATE, DELETE, VALUES, EXECUTE, DECLARE,
151 CREATE TABLE AS, or CREATE MATERIALIZED VIEW AS statement, whose
152 execution plan you wish to see.
153
155 The command's result is a textual description of the plan selected for
156 the statement, optionally annotated with execution statistics.
157 Section 14.1 describes the information provided.
158
160 In order to allow the PostgreSQL query planner to make reasonably
161 informed decisions when optimizing queries, the pg_statistic data
162 should be up-to-date for all tables used in the query. Normally the
163 autovacuum daemon will take care of that automatically. But if a table
164 has recently had substantial changes in its contents, you might need to
165 do a manual ANALYZE(7) rather than wait for autovacuum to catch up with
166 the changes.
167
168 In order to measure the run-time cost of each node in the execution
169 plan, the current implementation of EXPLAIN ANALYZE adds profiling
170 overhead to query execution. As a result, running EXPLAIN ANALYZE on a
171 query can sometimes take significantly longer than executing the query
172 normally. The amount of overhead depends on the nature of the query, as
173 well as the platform being used. The worst case occurs for plan nodes
174 that in themselves require very little time per execution, and on
175 machines that have relatively slow operating system calls for obtaining
176 the time of day.
177
179 To show the plan for a simple query on a table with a single integer
180 column and 10000 rows:
181
182 EXPLAIN SELECT * FROM foo;
183
184 QUERY PLAN
185 ---------------------------------------------------------
186 Seq Scan on foo (cost=0.00..155.00 rows=10000 width=4)
187 (1 row)
188
189 Here is the same query, with JSON output formatting:
190
191 EXPLAIN (FORMAT JSON) SELECT * FROM foo;
192 QUERY PLAN
193 --------------------------------
194 [ +
195 { +
196 "Plan": { +
197 "Node Type": "Seq Scan",+
198 "Relation Name": "foo", +
199 "Alias": "foo", +
200 "Startup Cost": 0.00, +
201 "Total Cost": 155.00, +
202 "Plan Rows": 10000, +
203 "Plan Width": 4 +
204 } +
205 } +
206 ]
207 (1 row)
208
209 If there is an index and we use a query with an indexable WHERE
210 condition, EXPLAIN might show a different plan:
211
212 EXPLAIN SELECT * FROM foo WHERE i = 4;
213
214 QUERY PLAN
215 --------------------------------------------------------------
216 Index Scan using fi on foo (cost=0.00..5.98 rows=1 width=4)
217 Index Cond: (i = 4)
218 (2 rows)
219
220 Here is the same query, but in YAML format:
221
222 EXPLAIN (FORMAT YAML) SELECT * FROM foo WHERE i='4';
223 QUERY PLAN
224 -------------------------------
225 - Plan: +
226 Node Type: "Index Scan" +
227 Scan Direction: "Forward"+
228 Index Name: "fi" +
229 Relation Name: "foo" +
230 Alias: "foo" +
231 Startup Cost: 0.00 +
232 Total Cost: 5.98 +
233 Plan Rows: 1 +
234 Plan Width: 4 +
235 Index Cond: "(i = 4)"
236 (1 row)
237
238 XML format is left as an exercise for the reader.
239
240 Here is the same plan with cost estimates suppressed:
241
242 EXPLAIN (COSTS FALSE) SELECT * FROM foo WHERE i = 4;
243
244 QUERY PLAN
245 ----------------------------
246 Index Scan using fi on foo
247 Index Cond: (i = 4)
248 (2 rows)
249
250 Here is an example of a query plan for a query using an aggregate
251 function:
252
253 EXPLAIN SELECT sum(i) FROM foo WHERE i < 10;
254
255 QUERY PLAN
256 ---------------------------------------------------------------------
257 Aggregate (cost=23.93..23.93 rows=1 width=4)
258 -> Index Scan using fi on foo (cost=0.00..23.92 rows=6 width=4)
259 Index Cond: (i < 10)
260 (3 rows)
261
262 Here is an example of using EXPLAIN EXECUTE to display the execution
263 plan for a prepared query:
264
265 PREPARE query(int, int) AS SELECT sum(bar) FROM test
266 WHERE id > $1 AND id < $2
267 GROUP BY foo;
268
269 EXPLAIN ANALYZE EXECUTE query(100, 200);
270
271 QUERY PLAN
272 ------------------------------------------------------------------------------------------------------------------------
273 HashAggregate (cost=9.54..9.54 rows=1 width=8) (actual time=0.156..0.161 rows=11 loops=1)
274 Group Key: foo
275 -> 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)
276 Index Cond: ((id > $1) AND (id < $2))
277 Planning time: 0.197 ms
278 Execution time: 0.225 ms
279 (6 rows)
280
281 Of course, the specific numbers shown here depend on the actual
282 contents of the tables involved. Also note that the numbers, and even
283 the selected query strategy, might vary between PostgreSQL releases due
284 to planner improvements. In addition, the ANALYZE command uses random
285 sampling to estimate data statistics; therefore, it is possible for
286 cost estimates to change after a fresh run of ANALYZE, even if the
287 actual distribution of data in the table has not changed.
288
290 There is no EXPLAIN statement defined in the SQL standard.
291
293 ANALYZE(7)
294
295
296
297PostgreSQL 13.4 2021 EXPLAIN(7)