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