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