1ANALYZE(7) PostgreSQL 11.6 Documentation ANALYZE(7)
2
3
4
6 ANALYZE - collect statistics about a database
7
9 ANALYZE [ ( option [, ...] ) ] [ table_and_columns [, ...] ]
10 ANALYZE [ VERBOSE ] [ table_and_columns [, ...] ]
11
12 where option can be one of:
13
14 VERBOSE
15
16 and table_and_columns is:
17
18 table_name [ ( column_name [, ...] ) ]
19
21 ANALYZE collects statistics about the contents of tables in the
22 database, and stores the results in the pg_statistic system catalog.
23 Subsequently, the query planner uses these statistics to help determine
24 the most efficient execution plans for queries.
25
26 Without a table_and_columns list, ANALYZE processes every table and
27 materialized view in the current database that the current user has
28 permission to analyze. With a list, ANALYZE processes only those
29 table(s). It is further possible to give a list of column names for a
30 table, in which case only the statistics for those columns are
31 collected.
32
33 When the option list is surrounded by parentheses, the options can be
34 written in any order. The parenthesized syntax was added in PostgreSQL
35 11; the unparenthesized syntax is deprecated.
36
38 VERBOSE
39 Enables display of progress messages.
40
41 table_name
42 The name (possibly schema-qualified) of a specific table to
43 analyze. If omitted, all regular tables, partitioned tables, and
44 materialized views in the current database are analyzed (but not
45 foreign tables). If the specified table is a partitioned table,
46 both the inheritance statistics of the partitioned table as a whole
47 and statistics of the individual partitions are updated.
48
49 column_name
50 The name of a specific column to analyze. Defaults to all columns.
51
53 When VERBOSE is specified, ANALYZE emits progress messages to indicate
54 which table is currently being processed. Various statistics about the
55 tables are printed as well.
56
58 To analyze a table, one must ordinarily be the table's owner or a
59 superuser. However, database owners are allowed to analyze all tables
60 in their databases, except shared catalogs. (The restriction for shared
61 catalogs means that a true database-wide ANALYZE can only be performed
62 by a superuser.) ANALYZE will skip over any tables that the calling
63 user does not have permission to analyze.
64
65 Foreign tables are analyzed only when explicitly selected. Not all
66 foreign data wrappers support ANALYZE. If the table's wrapper does not
67 support ANALYZE, the command prints a warning and does nothing.
68
69 In the default PostgreSQL configuration, the autovacuum daemon (see
70 Section 24.1.6) takes care of automatic analyzing of tables when they
71 are first loaded with data, and as they change throughout regular
72 operation. When autovacuum is disabled, it is a good idea to run
73 ANALYZE periodically, or just after making major changes in the
74 contents of a table. Accurate statistics will help the planner to
75 choose the most appropriate query plan, and thereby improve the speed
76 of query processing. A common strategy for read-mostly databases is to
77 run VACUUM(7) and ANALYZE once a day during a low-usage time of day.
78 (This will not be sufficient if there is heavy update activity.)
79
80 ANALYZE requires only a read lock on the target table, so it can run in
81 parallel with other activity on the table.
82
83 The statistics collected by ANALYZE usually include a list of some of
84 the most common values in each column and a histogram showing the
85 approximate data distribution in each column. One or both of these can
86 be omitted if ANALYZE deems them uninteresting (for example, in a
87 unique-key column, there are no common values) or if the column data
88 type does not support the appropriate operators. There is more
89 information about the statistics in Chapter 24.
90
91 For large tables, ANALYZE takes a random sample of the table contents,
92 rather than examining every row. This allows even very large tables to
93 be analyzed in a small amount of time. Note, however, that the
94 statistics are only approximate, and will change slightly each time
95 ANALYZE is run, even if the actual table contents did not change. This
96 might result in small changes in the planner's estimated costs shown by
97 EXPLAIN(7). In rare situations, this non-determinism will cause the
98 planner's choices of query plans to change after ANALYZE is run. To
99 avoid this, raise the amount of statistics collected by ANALYZE, as
100 described below.
101
102 The extent of analysis can be controlled by adjusting the
103 default_statistics_target configuration variable, or on a
104 column-by-column basis by setting the per-column statistics target with
105 ALTER TABLE ... ALTER COLUMN ... SET STATISTICS (see ALTER TABLE
106 (ALTER_TABLE(7))). The target value sets the maximum number of entries
107 in the most-common-value list and the maximum number of bins in the
108 histogram. The default target value is 100, but this can be adjusted up
109 or down to trade off accuracy of planner estimates against the time
110 taken for ANALYZE and the amount of space occupied in pg_statistic. In
111 particular, setting the statistics target to zero disables collection
112 of statistics for that column. It might be useful to do that for
113 columns that are never used as part of the WHERE, GROUP BY, or ORDER BY
114 clauses of queries, since the planner will have no use for statistics
115 on such columns.
116
117 The largest statistics target among the columns being analyzed
118 determines the number of table rows sampled to prepare the statistics.
119 Increasing the target causes a proportional increase in the time and
120 space needed to do ANALYZE.
121
122 One of the values estimated by ANALYZE is the number of distinct values
123 that appear in each column. Because only a subset of the rows are
124 examined, this estimate can sometimes be quite inaccurate, even with
125 the largest possible statistics target. If this inaccuracy leads to bad
126 query plans, a more accurate value can be determined manually and then
127 installed with ALTER TABLE ... ALTER COLUMN ... SET (n_distinct = ...)
128 (see ALTER TABLE (ALTER_TABLE(7))).
129
130 If the table being analyzed has one or more children, ANALYZE will
131 gather statistics twice: once on the rows of the parent table only, and
132 a second time on the rows of the parent table with all of its children.
133 This second set of statistics is needed when planning queries that
134 traverse the entire inheritance tree. The autovacuum daemon, however,
135 will only consider inserts or updates on the parent table itself when
136 deciding whether to trigger an automatic analyze for that table. If
137 that table is rarely inserted into or updated, the inheritance
138 statistics will not be up to date unless you run ANALYZE manually.
139
140 If any of the child tables are foreign tables whose foreign data
141 wrappers do not support ANALYZE, those child tables are ignored while
142 gathering inheritance statistics.
143
144 If the table being analyzed is completely empty, ANALYZE will not
145 record new statistics for that table. Any existing statistics will be
146 retained.
147
149 There is no ANALYZE statement in the SQL standard.
150
152 VACUUM(7), vacuumdb(1), Section 19.4.4, Section 24.1.6
153
154
155
156PostgreSQL 11.6 2019 ANALYZE(7)