1ANALYZE(7) PostgreSQL 11.3 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 Foreign tables are analyzed only when explicitly selected. Not all
59 foreign data wrappers support ANALYZE. If the table's wrapper does not
60 support ANALYZE, the command prints a warning and does nothing.
61
62 In the default PostgreSQL configuration, the autovacuum daemon (see
63 Section 24.1.6) takes care of automatic analyzing of tables when they
64 are first loaded with data, and as they change throughout regular
65 operation. When autovacuum is disabled, it is a good idea to run
66 ANALYZE periodically, or just after making major changes in the
67 contents of a table. Accurate statistics will help the planner to
68 choose the most appropriate query plan, and thereby improve the speed
69 of query processing. A common strategy for read-mostly databases is to
70 run VACUUM(7) and ANALYZE once a day during a low-usage time of day.
71 (This will not be sufficient if there is heavy update activity.)
72
73 ANALYZE requires only a read lock on the target table, so it can run in
74 parallel with other activity on the table.
75
76 The statistics collected by ANALYZE usually include a list of some of
77 the most common values in each column and a histogram showing the
78 approximate data distribution in each column. One or both of these can
79 be omitted if ANALYZE deems them uninteresting (for example, in a
80 unique-key column, there are no common values) or if the column data
81 type does not support the appropriate operators. There is more
82 information about the statistics in Chapter 24.
83
84 For large tables, ANALYZE takes a random sample of the table contents,
85 rather than examining every row. This allows even very large tables to
86 be analyzed in a small amount of time. Note, however, that the
87 statistics are only approximate, and will change slightly each time
88 ANALYZE is run, even if the actual table contents did not change. This
89 might result in small changes in the planner's estimated costs shown by
90 EXPLAIN(7). In rare situations, this non-determinism will cause the
91 planner's choices of query plans to change after ANALYZE is run. To
92 avoid this, raise the amount of statistics collected by ANALYZE, as
93 described below.
94
95 The extent of analysis can be controlled by adjusting the
96 default_statistics_target configuration variable, or on a
97 column-by-column basis by setting the per-column statistics target with
98 ALTER TABLE ... ALTER COLUMN ... SET STATISTICS (see ALTER TABLE
99 (ALTER_TABLE(7))). The target value sets the maximum number of entries
100 in the most-common-value list and the maximum number of bins in the
101 histogram. The default target value is 100, but this can be adjusted up
102 or down to trade off accuracy of planner estimates against the time
103 taken for ANALYZE and the amount of space occupied in pg_statistic. In
104 particular, setting the statistics target to zero disables collection
105 of statistics for that column. It might be useful to do that for
106 columns that are never used as part of the WHERE, GROUP BY, or ORDER BY
107 clauses of queries, since the planner will have no use for statistics
108 on such columns.
109
110 The largest statistics target among the columns being analyzed
111 determines the number of table rows sampled to prepare the statistics.
112 Increasing the target causes a proportional increase in the time and
113 space needed to do ANALYZE.
114
115 One of the values estimated by ANALYZE is the number of distinct values
116 that appear in each column. Because only a subset of the rows are
117 examined, this estimate can sometimes be quite inaccurate, even with
118 the largest possible statistics target. If this inaccuracy leads to bad
119 query plans, a more accurate value can be determined manually and then
120 installed with ALTER TABLE ... ALTER COLUMN ... SET (n_distinct = ...)
121 (see ALTER TABLE (ALTER_TABLE(7))).
122
123 If the table being analyzed has one or more children, ANALYZE will
124 gather statistics twice: once on the rows of the parent table only, and
125 a second time on the rows of the parent table with all of its children.
126 This second set of statistics is needed when planning queries that
127 traverse the entire inheritance tree. The autovacuum daemon, however,
128 will only consider inserts or updates on the parent table itself when
129 deciding whether to trigger an automatic analyze for that table. If
130 that table is rarely inserted into or updated, the inheritance
131 statistics will not be up to date unless you run ANALYZE manually.
132
133 If any of the child tables are foreign tables whose foreign data
134 wrappers do not support ANALYZE, those child tables are ignored while
135 gathering inheritance statistics.
136
137 If the table being analyzed is completely empty, ANALYZE will not
138 record new statistics for that table. Any existing statistics will be
139 retained.
140
142 There is no ANALYZE statement in the SQL standard.
143
145 VACUUM(7), vacuumdb(1), Section 19.4.4, Section 24.1.6
146
147
148
149PostgreSQL 11.3 2019 ANALYZE(7)