File: planner-stats.html

package info (click to toggle)
postgresql-9.1 9.1.15-0%2Bdeb8u1
  • links: PTS, VCS
  • area: main
  • in suites: jessie-kfreebsd
  • size: 109,092 kB
  • sloc: ansic: 575,877; sql: 43,887; yacc: 26,399; perl: 6,352; lex: 6,171; sh: 5,282; makefile: 3,772; asm: 65; sed: 15; python: 12
file content (424 lines) | stat: -rw-r--r-- 8,966 bytes parent folder | download
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
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.01 Transitional//EN" "http://www.w3.org/TR/html4/loose.dtd">
<HTML
><HEAD
><TITLE
>Statistics Used by the Planner</TITLE
><META
NAME="GENERATOR"
CONTENT="Modular DocBook HTML Stylesheet Version 1.79"><LINK
REV="MADE"
HREF="mailto:pgsql-docs@postgresql.org"><LINK
REL="HOME"
TITLE="PostgreSQL 9.1.15 Documentation"
HREF="index.html"><LINK
REL="UP"
TITLE="Performance Tips"
HREF="performance-tips.html"><LINK
REL="PREVIOUS"
TITLE="Using EXPLAIN"
HREF="using-explain.html"><LINK
REL="NEXT"
TITLE="Controlling the Planner with Explicit JOIN Clauses"
HREF="explicit-joins.html"><LINK
REL="STYLESHEET"
TYPE="text/css"
HREF="stylesheet.css"><META
HTTP-EQUIV="Content-Type"
CONTENT="text/html; charset=ISO-8859-1"><META
NAME="creation"
CONTENT="2015-02-02T21:03:01"></HEAD
><BODY
CLASS="SECT1"
><DIV
CLASS="NAVHEADER"
><TABLE
SUMMARY="Header navigation table"
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TH
COLSPAN="5"
ALIGN="center"
VALIGN="bottom"
><A
HREF="index.html"
>PostgreSQL 9.1.15 Documentation</A
></TH
></TR
><TR
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
TITLE="Using EXPLAIN"
HREF="using-explain.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
HREF="performance-tips.html"
ACCESSKEY="U"
>Up</A
></TD
><TD
WIDTH="60%"
ALIGN="center"
VALIGN="bottom"
>Chapter 14. Performance Tips</TD
><TD
WIDTH="20%"
ALIGN="right"
VALIGN="top"
><A
TITLE="Controlling the Planner with Explicit JOIN Clauses"
HREF="explicit-joins.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
></TABLE
><HR
ALIGN="LEFT"
WIDTH="100%"></DIV
><DIV
CLASS="SECT1"
><H1
CLASS="SECT1"
><A
NAME="PLANNER-STATS"
>14.2. Statistics Used by the Planner</A
></H1
><P
>   As we saw in the previous section, the query planner needs to estimate
   the number of rows retrieved by a query in order to make good choices
   of query plans.  This section provides a quick look at the statistics
   that the system uses for these estimates.
  </P
><P
>   One component of the statistics is the total number of entries in
   each table and index, as well as the number of disk blocks occupied
   by each table and index.  This information is kept in the table
   <A
HREF="catalog-pg-class.html"
><TT
CLASS="STRUCTNAME"
>pg_class</TT
></A
>,
   in the columns <TT
CLASS="STRUCTFIELD"
>reltuples</TT
> and
   <TT
CLASS="STRUCTFIELD"
>relpages</TT
>.  We can look at it with
   queries similar to this one:

</P><PRE
CLASS="SCREEN"
>SELECT relname, relkind, reltuples, relpages
FROM pg_class
WHERE relname LIKE 'tenk1%';

       relname        | relkind | reltuples | relpages
----------------------+---------+-----------+----------
 tenk1                | r       |     10000 |      358
 tenk1_hundred        | i       |     10000 |       30
 tenk1_thous_tenthous | i       |     10000 |       30
 tenk1_unique1        | i       |     10000 |       30
 tenk1_unique2        | i       |     10000 |       30
(5 rows)</PRE
><P>

   Here we can see that <TT
CLASS="STRUCTNAME"
>tenk1</TT
> contains 10000
   rows, as do its indexes, but the indexes are (unsurprisingly) much
   smaller than the table.
  </P
><P
>   For efficiency reasons, <TT
CLASS="STRUCTFIELD"
>reltuples</TT
>
   and <TT
CLASS="STRUCTFIELD"
>relpages</TT
> are not updated on-the-fly,
   and so they usually contain somewhat out-of-date values.
   They are updated by <TT
CLASS="COMMAND"
>VACUUM</TT
>, <TT
CLASS="COMMAND"
>ANALYZE</TT
>, and a
   few DDL commands such as <TT
CLASS="COMMAND"
>CREATE INDEX</TT
>.  A stand-alone
   <TT
CLASS="COMMAND"
>ANALYZE</TT
>, that is one not part of <TT
CLASS="COMMAND"
>VACUUM</TT
>,
   generates an approximate <TT
CLASS="STRUCTFIELD"
>reltuples</TT
> value
   since it does not read every row of the table.  The planner
   will scale the values it finds in <TT
CLASS="STRUCTNAME"
>pg_class</TT
>
   to match the current physical table size, thus obtaining a closer
   approximation.
  </P
><P
>   Most queries retrieve only a fraction of the rows in a table, due
   to <TT
CLASS="LITERAL"
>WHERE</TT
> clauses that restrict the rows to be
   examined.  The planner thus needs to make an estimate of the
   <I
CLASS="FIRSTTERM"
>selectivity</I
> of <TT
CLASS="LITERAL"
>WHERE</TT
> clauses, that is,
   the fraction of rows that match each condition in the
   <TT
CLASS="LITERAL"
>WHERE</TT
> clause.  The information used for this task is
   stored in the
   <A
HREF="catalog-pg-statistic.html"
><TT
CLASS="STRUCTNAME"
>pg_statistic</TT
></A
>
   system catalog.  Entries in <TT
CLASS="STRUCTNAME"
>pg_statistic</TT
>
   are updated by the <TT
CLASS="COMMAND"
>ANALYZE</TT
> and <TT
CLASS="COMMAND"
>VACUUM
   ANALYZE</TT
> commands, and are always approximate even when freshly
   updated.
  </P
><P
>   Rather than look at <TT
CLASS="STRUCTNAME"
>pg_statistic</TT
> directly,
   it's better to look at its view
   <A
HREF="view-pg-stats.html"
><TT
CLASS="STRUCTNAME"
>pg_stats</TT
></A
>
   when examining the statistics manually.  <TT
CLASS="STRUCTNAME"
>pg_stats</TT
>
   is designed to be more easily readable.  Furthermore,
   <TT
CLASS="STRUCTNAME"
>pg_stats</TT
> is readable by all, whereas
   <TT
CLASS="STRUCTNAME"
>pg_statistic</TT
> is only readable by a superuser.
   (This prevents unprivileged users from learning something about
   the contents of other people's tables from the statistics.  The
   <TT
CLASS="STRUCTNAME"
>pg_stats</TT
> view is restricted to show only
   rows about tables that the current user can read.)
   For example, we might do:

</P><PRE
CLASS="SCREEN"
>SELECT attname, inherited, n_distinct,
       array_to_string(most_common_vals, E'\n') as most_common_vals
FROM pg_stats
WHERE tablename = 'road';

 attname | inherited | n_distinct |          most_common_vals          
---------+-----------+------------+------------------------------------
 name    | f         |  -0.363388 | I- 580                        Ramp+
         |           |            | I- 880                        Ramp+
         |           |            | Sp Railroad                       +
         |           |            | I- 580                            +
         |           |            | I- 680                        Ramp
 name    | t         |  -0.284859 | I- 880                        Ramp+
         |           |            | I- 580                        Ramp+
         |           |            | I- 680                        Ramp+
         |           |            | I- 580                            +
         |           |            | State Hwy 13                  Ramp
(2 rows)</PRE
><P>

   Note that two rows are displayed for the same column, one corresponding
   to the complete inheritance hierarchy starting at the
   <TT
CLASS="LITERAL"
>road</TT
> table (<TT
CLASS="LITERAL"
>inherited</TT
>=<TT
CLASS="LITERAL"
>t</TT
>),
   and another one including only the <TT
CLASS="LITERAL"
>road</TT
> table itself
   (<TT
CLASS="LITERAL"
>inherited</TT
>=<TT
CLASS="LITERAL"
>f</TT
>).
  </P
><P
>   The amount of information stored in <TT
CLASS="STRUCTNAME"
>pg_statistic</TT
>
   by <TT
CLASS="COMMAND"
>ANALYZE</TT
>, in particular the maximum number of entries in the
   <TT
CLASS="STRUCTFIELD"
>most_common_vals</TT
> and <TT
CLASS="STRUCTFIELD"
>histogram_bounds</TT
>
   arrays for each column, can be set on a
   column-by-column basis using the <TT
CLASS="COMMAND"
>ALTER TABLE SET STATISTICS</TT
>
   command, or globally by setting the
   <A
HREF="runtime-config-query.html#GUC-DEFAULT-STATISTICS-TARGET"
>default_statistics_target</A
> configuration variable.
   The default limit is presently 100 entries.  Raising the limit
   might allow more accurate planner estimates to be made, particularly for
   columns with irregular data distributions, at the price of consuming
   more space in <TT
CLASS="STRUCTNAME"
>pg_statistic</TT
> and slightly more
   time to compute the estimates.  Conversely, a lower limit might be
   sufficient for columns with simple data distributions.
  </P
><P
>   Further details about the planner's use of statistics can be found in
   <A
HREF="planner-stats-details.html"
>Chapter 57</A
>.
  </P
></DIV
><DIV
CLASS="NAVFOOTER"
><HR
ALIGN="LEFT"
WIDTH="100%"><TABLE
SUMMARY="Footer navigation table"
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
><A
HREF="using-explain.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="index.html"
ACCESSKEY="H"
>Home</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
><A
HREF="explicit-joins.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
>Using <TT
CLASS="COMMAND"
>EXPLAIN</TT
></TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="performance-tips.html"
ACCESSKEY="U"
>Up</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
>Controlling the Planner with Explicit <TT
CLASS="LITERAL"
>JOIN</TT
> Clauses</TD
></TR
></TABLE
></DIV
></BODY
></HTML
>