1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
|
<!--
$PostgreSQL: pgsql/doc/src/sgml/ref/explain.sgml,v 1.35.6.1 2006/01/20 16:42:02 momjian Exp $
PostgreSQL documentation
-->
<refentry id="SQL-EXPLAIN">
<refmeta>
<refentrytitle id="SQL-EXPLAIN-TITLE">EXPLAIN</refentrytitle>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>EXPLAIN</refname>
<refpurpose>show the execution plan of a statement</refpurpose>
</refnamediv>
<indexterm zone="sql-explain">
<primary>EXPLAIN</primary>
</indexterm>
<indexterm zone="sql-explain">
<primary>prepared statements</primary>
<secondary>showing the query plan</secondary>
</indexterm>
<indexterm zone="sql-explain">
<primary>cursor</primary>
<secondary>showing the query plan</secondary>
</indexterm>
<refsynopsisdiv>
<synopsis>
EXPLAIN [ ANALYZE ] [ VERBOSE ] <replaceable class="parameter">statement</replaceable>
</synopsis>
</refsynopsisdiv>
<refsect1>
<title>Description</title>
<para>
This command displays the execution plan that the
<productname>PostgreSQL</productname> planner generates for the
supplied statement. The execution plan shows how the table(s)
referenced by the statement will be scanned — by plain sequential scan,
index scan, etc. — and if multiple tables are referenced, what join
algorithms will be used to bring together the required rows from
each input table.
</para>
<para>
The most critical part of the display is the estimated statement execution
cost, which is the planner's guess at how long it will take to run the
statement (measured in units of disk page fetches). Actually two numbers
are shown: the start-up time before the first row can be returned, and
the total time to return all the rows. For most queries the total time
is what matters, but in contexts such as a subquery in <literal>EXISTS</literal>, the planner
will choose the smallest start-up time instead of the smallest total time
(since the executor will stop after getting one row, anyway).
Also, if you limit the number of rows to return with a <literal>LIMIT</literal> clause,
the planner makes an appropriate interpolation between the endpoint
costs to estimate which plan is really the cheapest.
</para>
<para>
The <literal>ANALYZE</literal> option causes the statement to be actually executed, not only
planned. The total elapsed time expended within each plan node (in
milliseconds) and total number of rows it actually returned are added to
the display. This is useful for seeing whether the planner's estimates
are close to reality.
</para>
<important>
<para>
Keep in mind that the statement is actually executed when
<literal>ANALYZE</literal> is used. Although
<command>EXPLAIN</command> will discard any output that a
<command>SELECT</command> would return, other side effects of the
statement will happen as usual. If you wish to use
<command>EXPLAIN ANALYZE</command> on an
<command>INSERT</command>, <command>UPDATE</command>,
<command>DELETE</command>, or <command>EXECUTE</command> statement
without letting the command affect your data, use this approach:
<programlisting>
BEGIN;
EXPLAIN ANALYZE ...;
ROLLBACK;
</programlisting>
</para>
</important>
</refsect1>
<refsect1>
<title>Parameters</title>
<variablelist>
<varlistentry>
<term><literal>ANALYZE</literal></term>
<listitem>
<para>
Carry out the command and show the actual run times.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>VERBOSE</literal></term>
<listitem>
<para>
Show the full internal representation of the plan tree, rather
than just a summary. Usually this option is only useful for
specialized debugging purposes. The
<literal>VERBOSE</literal> output is either pretty-printed or
not, depending on the setting of the <xref
linkend="guc-explain-pretty-print"> configuration parameter.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">statement</replaceable></term>
<listitem>
<para>
Any <command>SELECT</>, <command>INSERT</>, <command>UPDATE</>,
<command>DELETE</>, <command>EXECUTE</>, or <command>DECLARE</>
statement, whose execution plan you wish to see.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Notes</title>
<para>
There is only sparse documentation on the optimizer's use of cost
information in <productname>PostgreSQL</productname>. Refer to
<xref linkend="using-explain"> for more information.
</para>
<para>
In order to allow the <productname>PostgreSQL</productname> query
planner to make reasonably informed decisions when optimizing
queries, the <command>ANALYZE</command> statement should be run to
record statistics about the distribution of data within the
table. If you have not done this (or if the statistical
distribution of the data in the table has changed significantly
since the last time <command>ANALYZE</command> was run), the
estimated costs are unlikely to conform to the real properties of
the query, and consequently an inferior query plan may be chosen.
</para>
<para>
Genetic query optimization (<acronym>GEQO</acronym>) randomly
tests execution plans. Therefore, when the number of tables exceeds
<varname>geqo_threshold</> causing genetic query optimization to be
used, the execution plan is likely to change each time the statement
is executed.
</para>
<para>
Prior to <productname>PostgreSQL</productname> 7.3, the plan was
emitted in the form of a <literal>NOTICE</literal> message. Now it
appears as a query result (formatted like a table with a single
text column).
</para>
</refsect1>
<refsect1>
<title>Examples</title>
<para>
To show the plan for a simple query on a table with a single
<type>integer</type> column and 10000 rows:
<programlisting>
EXPLAIN SELECT * FROM foo;
QUERY PLAN
---------------------------------------------------------
Seq Scan on foo (cost=0.00..155.00 rows=10000 width=4)
(1 row)
</programlisting>
</para>
<para>
If there is an index and we use a query with an indexable
<literal>WHERE</literal> condition, <command>EXPLAIN</command>
might show a different plan:
<programlisting>
EXPLAIN SELECT * FROM foo WHERE i = 4;
QUERY PLAN
--------------------------------------------------------------
Index Scan using fi on foo (cost=0.00..5.98 rows=1 width=4)
Index Cond: (i = 4)
(2 rows)
</programlisting>
</para>
<para>
And here is an example of a query plan for a query
using an aggregate function:
<programlisting>
EXPLAIN SELECT sum(i) FROM foo WHERE i < 10;
QUERY PLAN
---------------------------------------------------------------------
Aggregate (cost=23.93..23.93 rows=1 width=4)
-> Index Scan using fi on foo (cost=0.00..23.92 rows=6 width=4)
Index Cond: (i < 10)
(3 rows)
</programlisting>
</para>
<para>
Here is an example of using <command>EXPLAIN EXECUTE</command> to
display the execution plan for a prepared query:
<programlisting>
PREPARE query(int, int) AS SELECT sum(bar) FROM test
WHERE id > $1 AND id < $2
GROUP BY foo;
EXPLAIN ANALYZE EXECUTE query(100, 200);
QUERY PLAN
-------------------------------------------------------------------------------------------------------------------------
HashAggregate (cost=39.53..39.53 rows=1 width=8) (actual time=0.661..0.672 rows=7 loops=1)
-> 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)
Index Cond: ((id > $1) AND (id < $2))
Total runtime: 0.851 ms
(4 rows)
</programlisting>
</para>
<para>
Of course, the specific numbers shown here depend on the actual
contents of the tables involved. Also note that the numbers, and
even the selected query strategy, may vary between
<productname>PostgreSQL</productname> releases due to planner
improvements. In addition, the <command>ANALYZE</command> command
uses random sampling to estimate data statistics; therefore, it is
possible for cost estimates to change after a fresh run of
<command>ANALYZE</command>, even if the actual distribution of data
in the table has not changed.
</para>
</refsect1>
<refsect1>
<title>Compatibility</title>
<para>
There is no <command>EXPLAIN</command> statement defined in the SQL standard.
</para>
</refsect1>
<refsect1>
<title>See Also</title>
<simplelist type="inline">
<member><xref linkend="sql-analyze" endterm="sql-analyze-title"></member>
</simplelist>
</refsect1>
</refentry>
<!-- Keep this comment at the end of the file
Local variables:
mode: sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"../reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:"/usr/lib/sgml/catalog"
sgml-local-ecat-files:nil
End:
-->
|