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