Home Explore Blog CI



postgresql

4th chunk of `doc/src/sgml/ref/analyze.sgml`
7176bd781bbb862e3699b86e1a0e56fc97f020e141637c630000000100000b9b
 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
   <link linkend="sql-explain"><command>EXPLAIN</command></link>.
   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 <link linkend="sql-altertable"><command>ALTER TABLE ... ALTER COLUMN ... SET
   STATISTICS</command></link>.
   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>, <literal>GROUP BY</literal>,
   or <literal>ORDER BY</literal> 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
   <link linkend="sql-altertable"><command>ALTER TABLE ... ALTER COLUMN ... SET (n_distinct = ...)</command></link>.
  </para>

  <para>
    If the table being analyzed has inheritance children,
   

Title: Controlling ANALYZE Statistics and Estimates
Summary
This section explains how to control the extent of analysis performed by ANALYZE using the `default_statistics_target` configuration variable or by setting per-column statistics targets with `ALTER TABLE`. It describes how the target value affects the size of the most-common-value list and histogram, and the trade-offs between accuracy, time, and space. It also discusses how to manually set the number of distinct values for a column using `ALTER TABLE` if the estimate provided by ANALYZE is inaccurate.