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