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