summaryrefslogtreecommitdiff
path: root/doc/src/sgml/ref/analyze.sgml
blob: c0d2673dc50f01d0d6ece91ee1689d3329842233 (plain)
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
<!--
$PostgreSQL: pgsql/doc/src/sgml/ref/analyze.sgml,v 1.26 2009/08/02 22:14:51 tgl Exp $
PostgreSQL documentation
-->

<refentry id="SQL-ANALYZE">
 <refmeta>
  <refentrytitle id="sql-analyze-title">ANALYZE</refentrytitle>
  <manvolnum>7</manvolnum>
  <refmiscinfo>SQL - Language Statements</refmiscinfo>
 </refmeta>

 <refnamediv>
  <refname>ANALYZE</refname>
  <refpurpose>collect statistics about a database</refpurpose>
 </refnamediv>

 <indexterm zone="sql-analyze">
  <primary>ANALYZE</primary>
 </indexterm>

 <refsynopsisdiv>
<synopsis>
ANALYZE [ VERBOSE ] [ <replaceable class="PARAMETER">table</replaceable> [ ( <replaceable class="PARAMETER">column</replaceable> [, ...] ) ] ]
</synopsis>
 </refsynopsisdiv>

 <refsect1>
  <title>Description</title>

  <para>
   <command>ANALYZE</command> collects statistics about the contents
   of tables in the database, and stores the results in the <link
   linkend="catalog-pg-statistic"><structname>pg_statistic</></>
   system catalog.  Subsequently, the query planner uses these
   statistics to help determine the most efficient execution plans for
   queries.
  </para>

  <para>
   With no parameter, <command>ANALYZE</command> examines every table in the
   current database.  With a parameter, <command>ANALYZE</command> examines
   only that table.  It is further possible to give a list of column names,
   in which case only the statistics for those columns are collected.
  </para>
 </refsect1>

 <refsect1>
  <title>Parameters</title>

  <variablelist>
   <varlistentry>
    <term><literal>VERBOSE</literal></term>
    <listitem>
     <para>
      Enables display of progress messages.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="PARAMETER">table</replaceable></term>
    <listitem>
     <para>
      The name (possibly schema-qualified) of a specific table to
      analyze. Defaults to all tables in the current database.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="PARAMETER">column</replaceable></term>
    <listitem>
     <para>
      The name of a specific column to analyze. Defaults to all columns.
     </para>
    </listitem>
   </varlistentry>
  </variablelist>
 </refsect1>

 <refsect1>
  <title>Outputs</title>

   <para>
    When <literal>VERBOSE</> is specified, <command>ANALYZE</> emits
    progress messages to indicate which table is currently being
    processed.  Various statistics about the tables are printed as well.
   </para>
 </refsect1>

 <refsect1>
  <title>Notes</title>

  <para>
   In the default <productname>PostgreSQL</productname> configuration,
   <xref linkend="autovacuum" endterm="autovacuum-title">
   takes care of automatic analyzing of tables when they are first loaded
   with data, and as they change throughout regular operation.
   When autovacuum is disabled,
   it is a good idea to run <command>ANALYZE</command> periodically, or
   just after making major changes in the contents of a table.  Accurate
   statistics will help the planner to choose the most appropriate query
   plan, and thereby improve the speed of query processing.  A common
   strategy is to run <xref linkend="sql-vacuum" endterm="sql-vacuum-title">
   and <command>ANALYZE</command> once a day during a low-usage time of day.
  </para>

  <para>
   <command>ANALYZE</command>
   requires only a read lock on the target table, so it can run in
   parallel with other activity on the table.
  </para>

  <para>
   The statistics collected by <command>ANALYZE</command> usually
   include a list of some of the most common values in each column and
   a histogram showing the approximate data distribution in each
   column.  One or both of these can be omitted if
   <command>ANALYZE</command> deems them uninteresting (for example,
   in a unique-key column, there are no common values) or if the
   column data type does not support the appropriate operators.  There
   is more information about the statistics in <xref
   linkend="maintenance">.
  </para>

  <para>
   For large tables, <command>ANALYZE</command> takes a random sample
   of the table contents, rather than examining every row.  This
   allows even very large tables to be analyzed in a small amount of
   time.  Note, however, that the statistics are only approximate, and
   will change slightly each time <command>ANALYZE</command> is run,
   even if the actual table contents did not change.  This might result
   in small changes in the planner's estimated costs shown by
   <xref linkend="sql-explain" endterm="sql-explain-title">.
   In rare situations, this non-determinism will cause the planner's
   choices of query plans to change after <command>ANALYZE</command> is run.
   To avoid this, raise the amount of statistics collected by
   <command>ANALYZE</command>, as described below.
  </para>

  <para>
   The extent of analysis can be controlled by adjusting the
   <xref linkend="guc-default-statistics-target"> configuration variable, or
   on a column-by-column basis by setting the per-column statistics
   target with <command>ALTER TABLE ... ALTER COLUMN ... SET
   STATISTICS</command> (see <xref linkend="sql-altertable"
   endterm="sql-altertable-title">).  The target value sets the
   maximum number of entries in the most-common-value list and the
   maximum number of bins in the histogram.  The default target value
   is 100, but this can be adjusted up or down to trade off accuracy of
   planner estimates against the time taken for
   <command>ANALYZE</command> and the amount of space occupied in
   <literal>pg_statistic</literal>.  In particular, setting the
   statistics target to zero disables collection of statistics for
   that column.  It might be useful to do that for columns that are
   never used as part of the <literal>WHERE</>, <literal>GROUP BY</>,
   or <literal>ORDER BY</> clauses of queries, since the planner will
   have no use for statistics on such columns.
  </para>

  <para>
   The largest statistics target among the columns being analyzed determines
   the number of table rows sampled to prepare the statistics.  Increasing
   the target causes a proportional increase in the time and space needed
   to do <command>ANALYZE</command>.
  </para>

  <para>
   One of the values estimated by <command>ANALYZE</command> is the number of
   distinct values that appear in each column.  Because only a subset of the
   rows are examined, this estimate can sometimes be quite inaccurate, even
   with the largest possible statistics target.  If this inaccuracy leads to
   bad query plans, a more accurate value can be determined manually and then
   installed with
   <command>ALTER TABLE ... ALTER COLUMN ... SET STATISTICS DISTINCT</>
   (see <xref linkend="sql-altertable" endterm="sql-altertable-title">).
  </para>
 </refsect1>

 <refsect1>
  <title>Compatibility</title>

  <para>
   There is no <command>ANALYZE</command> statement in the SQL standard.
  </para>
 </refsect1>

 <refsect1>
  <title>See Also</title>

  <simplelist type="inline">
   <member><xref linkend="sql-vacuum" endterm="sql-vacuum-title"></member>
   <member><xref linkend="app-vacuumdb" endterm="app-vacuumdb-title"></member>
   <member><xref linkend="runtime-config-resource-vacuum-cost" endterm="runtime-config-resource-vacuum-cost-title"></member>
   <member><xref linkend="autovacuum" endterm="autovacuum-title"></member>
  </simplelist>
 </refsect1>
</refentry>