summaryrefslogtreecommitdiffstats
path: root/doc/src/sgml/html/sql-analyze.html
blob: a0c7f73ccbd54617527c1db7c0228017b73d355a (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
<?xml version="1.0" encoding="UTF-8" standalone="no"?>
<!DOCTYPE html PUBLIC "-//W3C//DTD XHTML 1.0 Transitional//EN" "http://www.w3.org/TR/xhtml1/DTD/xhtml1-transitional.dtd"><html xmlns="http://www.w3.org/1999/xhtml"><head><meta http-equiv="Content-Type" content="text/html; charset=UTF-8" /><title>ANALYZE</title><link rel="stylesheet" type="text/css" href="stylesheet.css" /><link rev="made" href="pgsql-docs@lists.postgresql.org" /><meta name="generator" content="DocBook XSL Stylesheets V1.79.1" /><link rel="prev" href="sql-alterview.html" title="ALTER VIEW" /><link rel="next" href="sql-begin.html" title="BEGIN" /></head><body id="docContent" class="container-fluid col-10"><div xmlns="http://www.w3.org/TR/xhtml1/transitional" class="navheader"><table width="100%" summary="Navigation header"><tr><th colspan="5" align="center">ANALYZE</th></tr><tr><td width="10%" align="left"><a accesskey="p" href="sql-alterview.html" title="ALTER VIEW">Prev</a> </td><td width="10%" align="left"><a accesskey="u" href="sql-commands.html" title="SQL Commands">Up</a></td><th width="60%" align="center">SQL Commands</th><td width="10%" align="right"><a accesskey="h" href="index.html" title="PostgreSQL 13.4 Documentation">Home</a></td><td width="10%" align="right"> <a accesskey="n" href="sql-begin.html" title="BEGIN">Next</a></td></tr></table><hr></hr></div><div class="refentry" id="SQL-ANALYZE"><div class="titlepage"></div><a id="id-1.9.3.46.1" class="indexterm"></a><div class="refnamediv"><h2><span class="refentrytitle">ANALYZE</span></h2><p>ANALYZE — collect statistics about a database</p></div><div class="refsynopsisdiv"><h2>Synopsis</h2><pre class="synopsis">
ANALYZE [ ( <em class="replaceable"><code>option</code></em> [, ...] ) ] [ <em class="replaceable"><code>table_and_columns</code></em> [, ...] ]
ANALYZE [ VERBOSE ] [ <em class="replaceable"><code>table_and_columns</code></em> [, ...] ]

<span class="phrase">where <em class="replaceable"><code>option</code></em> can be one of:</span>

    VERBOSE [ <em class="replaceable"><code>boolean</code></em> ]
    SKIP_LOCKED [ <em class="replaceable"><code>boolean</code></em> ]

<span class="phrase">and <em class="replaceable"><code>table_and_columns</code></em> is:</span>

    <em class="replaceable"><code>table_name</code></em> [ ( <em class="replaceable"><code>column_name</code></em> [, ...] ) ]
</pre></div><div class="refsect1" id="id-1.9.3.46.5"><h2>Description</h2><p>
   <code class="command">ANALYZE</code> collects statistics about the contents
   of tables in the database, and stores the results in the <a class="link" href="catalog-pg-statistic.html" title="51.49. pg_statistic"><code class="structname">pg_statistic</code></a>
   system catalog.  Subsequently, the query planner uses these
   statistics to help determine the most efficient execution plans for
   queries.
  </p><p>
   Without a <em class="replaceable"><code>table_and_columns</code></em>
   list, <code class="command">ANALYZE</code> processes every table and materialized view
   in the current database that the current user has permission to analyze.
   With a list, <code class="command">ANALYZE</code> processes only those table(s).
   It is further possible to give a list of column names for a table,
   in which case only the statistics for those columns are collected.
  </p><p>
   When the option list is surrounded by parentheses, the options can be
   written in any order.  The parenthesized syntax was added in
   <span class="productname">PostgreSQL</span> 11;  the unparenthesized syntax
   is deprecated.
  </p></div><div class="refsect1" id="id-1.9.3.46.6"><h2>Parameters</h2><div class="variablelist"><dl class="variablelist"><dt><span class="term"><code class="literal">VERBOSE</code></span></dt><dd><p>
      Enables display of progress messages.
     </p></dd><dt><span class="term"><code class="literal">SKIP_LOCKED</code></span></dt><dd><p>
      Specifies that <code class="command">ANALYZE</code> should not wait for any
      conflicting locks to be released when beginning work on a relation:
      if a relation cannot be locked immediately without waiting, the relation
      is skipped.  Note that even with this option, <code class="command">ANALYZE</code>
      may still block when opening the relation's indexes or when acquiring
      sample rows from partitions, table inheritance children, and some
      types of foreign tables.  Also, while <code class="command">ANALYZE</code>
      ordinarily processes all partitions of specified partitioned tables,
      this option will cause <code class="command">ANALYZE</code> to skip all
      partitions if there is a conflicting lock on the partitioned table.
     </p></dd><dt><span class="term"><em class="replaceable"><code>boolean</code></em></span></dt><dd><p>
      Specifies whether the selected option should be turned on or off.
      You can write <code class="literal">TRUE</code>, <code class="literal">ON</code>, or
      <code class="literal">1</code> to enable the option, and <code class="literal">FALSE</code>,
      <code class="literal">OFF</code>, or <code class="literal">0</code> to disable it.  The
      <em class="replaceable"><code>boolean</code></em> value can also
      be omitted, in which case <code class="literal">TRUE</code> is assumed.
     </p></dd><dt><span class="term"><em class="replaceable"><code>table_name</code></em></span></dt><dd><p>
      The name (possibly schema-qualified) of a specific table to
      analyze.  If omitted, all regular tables, partitioned tables, and
      materialized views in the current database are analyzed (but not
      foreign tables).  If the specified table is a partitioned table, both the
      inheritance statistics of the partitioned table as a whole and
      statistics of the individual partitions are updated.
     </p></dd><dt><span class="term"><em class="replaceable"><code>column_name</code></em></span></dt><dd><p>
      The name of a specific column to analyze. Defaults to all columns.
     </p></dd></dl></div></div><div class="refsect1" id="id-1.9.3.46.7"><h2>Outputs</h2><p>
    When <code class="literal">VERBOSE</code> is specified, <code class="command">ANALYZE</code> emits
    progress messages to indicate which table is currently being
    processed.  Various statistics about the tables are printed as well.
   </p></div><div class="refsect1" id="id-1.9.3.46.8"><h2>Notes</h2><p>
   To analyze a table, one must ordinarily be the table's owner or a
   superuser.  However, database owners are allowed to
   analyze all tables in their databases, except shared catalogs.
   (The restriction for shared catalogs means that a true database-wide
   <code class="command">ANALYZE</code> can only be performed by a superuser.)
   <code class="command">ANALYZE</code> will skip over any tables that the calling user
   does not have permission to analyze.
  </p><p>
   Foreign tables are analyzed only when explicitly selected.  Not all
   foreign data wrappers support <code class="command">ANALYZE</code>.  If the table's
   wrapper does not support <code class="command">ANALYZE</code>, the command prints a
   warning and does nothing.
  </p><p>
   In the default <span class="productname">PostgreSQL</span> configuration,
   the autovacuum daemon (see <a class="xref" href="routine-vacuuming.html#AUTOVACUUM" title="24.1.6. The Autovacuum Daemon">Section 24.1.6</a>)
   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 <code class="command">ANALYZE</code> 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 for read-mostly databases is to run <a class="xref" href="sql-vacuum.html" title="VACUUM"><span class="refentrytitle">VACUUM</span></a>
   and <code class="command">ANALYZE</code> once a day during a low-usage time of day.
   (This will not be sufficient if there is heavy update activity.)
  </p><p>
   <code class="command">ANALYZE</code>
   requires only a read lock on the target table, so it can run in
   parallel with other activity on the table.
  </p><p>
   The statistics collected by <code class="command">ANALYZE</code> 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
   <code class="command">ANALYZE</code> 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 <a class="xref" href="maintenance.html" title="Chapter 24. Routine Database Maintenance Tasks">Chapter 24</a>.
  </p><p>
   For large tables, <code class="command">ANALYZE</code> 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 <code class="command">ANALYZE</code> 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
   <a class="xref" href="sql-explain.html" title="EXPLAIN"><span class="refentrytitle">EXPLAIN</span></a>.
   In rare situations, this non-determinism will cause the planner's
   choices of query plans to change after <code class="command">ANALYZE</code> is run.
   To avoid this, raise the amount of statistics collected by
   <code class="command">ANALYZE</code>, as described below.
  </p><p>
   The extent of analysis can be controlled by adjusting the
   <a class="xref" href="runtime-config-query.html#GUC-DEFAULT-STATISTICS-TARGET">default_statistics_target</a> configuration variable, or
   on a column-by-column basis by setting the per-column statistics
   target with <code class="command">ALTER TABLE ... ALTER COLUMN ... SET
   STATISTICS</code> (see <a class="xref" href="sql-altertable.html" title="ALTER TABLE"><span class="refentrytitle">ALTER TABLE</span></a>).
   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
   <code class="command">ANALYZE</code> and the amount of space occupied in
   <code class="literal">pg_statistic</code>.  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 <code class="literal">WHERE</code>, <code class="literal">GROUP BY</code>,
   or <code class="literal">ORDER BY</code> clauses of queries, since the planner will
   have no use for statistics on such columns.
  </p><p>
   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 <code class="command">ANALYZE</code>.
  </p><p>
   One of the values estimated by <code class="command">ANALYZE</code> 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
   <code class="command">ALTER TABLE ... ALTER COLUMN ... SET (n_distinct = ...)</code>
   (see <a class="xref" href="sql-altertable.html" title="ALTER TABLE"><span class="refentrytitle">ALTER TABLE</span></a>).
  </p><p>
    If the table being analyzed has one or more children,
    <code class="command">ANALYZE</code> will gather statistics twice: once on the
    rows of the parent table only, and a second time on the rows of the
    parent table with all of its children.  This second set of statistics
    is needed when planning queries that traverse the entire inheritance
    tree.  The autovacuum daemon, however, will only consider inserts or
    updates on the parent table itself when deciding whether to trigger an
    automatic analyze for that table.  If that table is rarely inserted into
    or updated, the inheritance statistics will not be up to date unless you
    run <code class="command">ANALYZE</code> manually.
  </p><p>
    If any of the child tables are foreign tables whose foreign data wrappers
    do not support <code class="command">ANALYZE</code>, those child tables are ignored while
    gathering inheritance statistics.
  </p><p>
    If the table being analyzed is completely empty, <code class="command">ANALYZE</code>
    will not record new statistics for that table.  Any existing statistics
    will be retained.
  </p></div><div class="refsect1" id="id-1.9.3.46.9"><h2>Compatibility</h2><p>
   There is no <code class="command">ANALYZE</code> statement in the SQL standard.
  </p></div><div class="refsect1" id="id-1.9.3.46.10"><h2>See Also</h2><span class="simplelist"><a class="xref" href="sql-vacuum.html" title="VACUUM"><span class="refentrytitle">VACUUM</span></a>, <a class="xref" href="app-vacuumdb.html" title="vacuumdb"><span class="refentrytitle"><span class="application">vacuumdb</span></span></a>, <a class="xref" href="runtime-config-resource.html#RUNTIME-CONFIG-RESOURCE-VACUUM-COST" title="19.4.4. Cost-based Vacuum Delay">Section 19.4.4</a>, <a class="xref" href="routine-vacuuming.html#AUTOVACUUM" title="24.1.6. The Autovacuum Daemon">Section 24.1.6</a></span></div></div><div xmlns="http://www.w3.org/TR/xhtml1/transitional" class="navfooter"><hr></hr><table width="100%" summary="Navigation footer"><tr><td width="40%" align="left"><a accesskey="p" href="sql-alterview.html" title="ALTER VIEW">Prev</a> </td><td width="20%" align="center"><a accesskey="u" href="sql-commands.html" title="SQL Commands">Up</a></td><td width="40%" align="right"> <a accesskey="n" href="sql-begin.html" title="BEGIN">Next</a></td></tr><tr><td width="40%" align="left" valign="top">ALTER VIEW </td><td width="20%" align="center"><a accesskey="h" href="index.html" title="PostgreSQL 13.4 Documentation">Home</a></td><td width="40%" align="right" valign="top"> BEGIN</td></tr></table></div></body></html>