1
0
mirror of https://github.com/postgres/postgres.git synced 2025-12-21 05:21:08 +03:00

Rewrite of planner statistics-gathering code. ANALYZE is now available as

a separate statement (though it can still be invoked as part of VACUUM, too).
pg_statistic redesigned to be more flexible about what statistics are
stored.  ANALYZE now collects a list of several of the most common values,
not just one, plus a histogram (not just the min and max values).  Random
sampling is used to make the process reasonably fast even on very large
tables.  The number of values and histogram bins collected is now
user-settable via an ALTER TABLE command.

There is more still to do; the new stats are not being used everywhere
they could be in the planner.  But the remaining changes for this project
should be localized, and the behavior is already better than before.

A not-very-related change is that sorting now makes use of btree comparison
routines if it can find one, rather than invoking '<' twice.
This commit is contained in:
Tom Lane
2001-05-07 00:43:27 +00:00
parent 9583aea9d0
commit f905d65ee3
66 changed files with 4131 additions and 2063 deletions

View File

@@ -1,5 +1,5 @@
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/allfiles.sgml,v 1.27 2001/01/13 03:11:12 petere Exp $
$Header: /cvsroot/pgsql/doc/src/sgml/ref/allfiles.sgml,v 1.28 2001/05/07 00:43:14 tgl Exp $
Postgres documentation
Complete list of usable sgml source files in this directory.
-->
@@ -40,6 +40,7 @@ Complete list of usable sgml source files in this directory.
<!entity alterGroup system "alter_group.sgml">
<!entity alterTable system "alter_table.sgml">
<!entity alterUser system "alter_user.sgml">
<!entity analyze system "analyze.sgml">
<!entity begin system "begin.sgml">
<!entity checkpoint system "checkpoint.sgml">
<!entity close system "close.sgml">

View File

@@ -1,5 +1,5 @@
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/alter_table.sgml,v 1.22 2001/03/05 18:42:55 momjian Exp $
$Header: /cvsroot/pgsql/doc/src/sgml/ref/alter_table.sgml,v 1.23 2001/05/07 00:43:15 tgl Exp $
Postgres documentation
-->
@@ -29,7 +29,9 @@ ALTER TABLE [ ONLY ] <replaceable class="PARAMETER">table</replaceable> [ * ]
ALTER TABLE [ ONLY ] <replaceable class="PARAMETER">table</replaceable> [ * ]
ALTER [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> { SET DEFAULT <replaceable
class="PARAMETER">value</replaceable> | DROP DEFAULT }
ALTER TABLE <replaceable class="PARAMETER">table</replaceable> [ * ]
ALTER TABLE [ ONLY ] <replaceable class="PARAMETER">table</replaceable> [ * ]
ALTER [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> SET STATISTICS <replaceable class="PARAMETER">integer</replaceable>
ALTER TABLE [ ONLY ] <replaceable class="PARAMETER">table</replaceable> [ * ]
RENAME [ COLUMN ] <replaceable class="PARAMETER">column</replaceable> TO <replaceable
class="PARAMETER">newcolumn</replaceable>
ALTER TABLE <replaceable class="PARAMETER">table</replaceable>
@@ -159,9 +161,14 @@ ALTER TABLE <replaceable class="PARAMETER">table</replaceable>
<command>ALTER TABLE</command> changes the definition of an existing table.
The <literal>ADD COLUMN</literal> form adds a new column to the table
using the same syntax as <xref linkend="SQL-CREATETABLE"
endterm="SQL-CREATETABLE-title">. The <literal>ALTER COLUMN</literal> form
allows you to set or remove the default for the column. Note that defaults
only apply to newly inserted rows.
endterm="SQL-CREATETABLE-title">.
The <literal>ALTER COLUMN SET/DROP DEFAULT</literal> forms
allow you to set or remove the default for the column. Note that defaults
only apply to subsequent <command>INSERT</command> commands; they do not
cause rows already in the table to change.
The <literal>ALTER COLUMN SET STATISTICS</literal> form allows you to
set the statistics-gathering target for subsequent
<xref linkend="sql-analyze" endterm="sql-analyze-title"> operations.
The <literal>RENAME</literal> clause causes the name of a table or column
to change without changing any of the data contained in
the affected table. Thus, the table or column will
@@ -170,7 +177,7 @@ ALTER TABLE <replaceable class="PARAMETER">table</replaceable>
The ADD <replaceable class="PARAMETER">table constraint definition</replaceable> clause
adds a new constraint to the table using the same syntax as <xref
linkend="SQL-CREATETABLE" endterm="SQL-CREATETABLE-title">.
The OWNER clause chnages the owner of the table to the user <replaceable class="PARAMETER">
The OWNER clause changes the owner of the table to the user <replaceable class="PARAMETER">
new user</replaceable>.
</para>
@@ -190,10 +197,11 @@ ALTER TABLE <replaceable class="PARAMETER">table</replaceable>
</para>
<para>
In the current implementation, default and constraint clauses for the
In the current implementation of <literal>ADD COLUMN</literal>,
default and constraint clauses for the
new column will be ignored. You can use the <literal>SET DEFAULT</literal>
form of <command>ALTER TABLE</command> to set the default later.
(You will also have to update the already existing rows to the
(You may also want to update the already existing rows to the
new default value, using <xref linkend="sql-update"
endterm="sql-update-title">.)
</para>
@@ -210,7 +218,7 @@ ALTER TABLE <replaceable class="PARAMETER">table</replaceable>
<para>
You must own the table in order to change it.
Renaming any part of the schema of a system
Changing any part of the schema of a system
catalog is not permitted.
The <citetitle>PostgreSQL User's Guide</citetitle> has further
information on inheritance.

View File

@@ -0,0 +1,219 @@
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/analyze.sgml,v 1.1 2001/05/07 00:43:15 tgl Exp $
Postgres documentation
-->
<refentry id="SQL-ANALYZE">
<refmeta>
<refentrytitle id="sql-analyze-title">
ANALYZE
</refentrytitle>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>
ANALYZE
</refname>
<refpurpose>
Collect statistics about a <productname>Postgres</productname> database
</refpurpose>
</refnamediv>
<refsynopsisdiv>
<refsynopsisdivinfo>
<date>2001-05-04</date>
</refsynopsisdivinfo>
<synopsis>
ANALYZE [ VERBOSE ] [ <replaceable class="PARAMETER">table</replaceable> [ (<replaceable class="PARAMETER">column</replaceable> [, ...] ) ] ]
</synopsis>
<refsect2 id="R2-SQL-ANALYZE-1">
<refsect2info>
<date>2001-05-04</date>
</refsect2info>
<title>
Inputs
</title>
<para>
<variablelist>
<varlistentry>
<term>VERBOSE</term>
<listitem>
<para>
Enables display of progress messages.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">table</replaceable></term>
<listitem>
<para>
The name of a specific table to analyze. Defaults to all tables.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">column</replaceable></term>
<listitem>
<para>
The name of a specific column to analyze. Defaults to all columns.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
<refsect2 id="R2-SQL-ANALYZE-2">
<refsect2info>
<date>2001-05-04</date>
</refsect2info>
<title>
Outputs
</title>
<para>
<variablelist>
<varlistentry>
<term><computeroutput>
<returnvalue>ANALYZE</returnvalue>
</computeroutput></term>
<listitem>
<para>
The command is complete.
</para>
</listitem>
</varlistentry>
</variablelist>
</para>
</refsect2>
</refsynopsisdiv>
<refsect1 id="R1-SQL-ANALYZE-1">
<refsect1info>
<date>2001-05-04</date>
</refsect1info>
<title>
Description
</title>
<para>
<command>ANALYZE</command> collects statistics about the contents of
<productname>Postgres</productname> tables, and stores the results in
the system table <literal>pg_statistic</literal>. Subsequently,
the query planner uses the statistics to help determine the most efficient
execution plans for queries.
</para>
<para>
With no parameter, <command>ANALYZE</command> examines every table in the
current database. With a parameter, <command>ANALYZE</command> examines
only that table. It is further possible to give a list of column names,
in which case only the statistics for those columns are updated.
</para>
<refsect2 id="R2-SQL-ANALYZE-3">
<refsect2info>
<date>2001-05-04</date>
</refsect2info>
<title>
Notes
</title>
<para>
It is a good idea to run <command>ANALYZE</command> 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 is to run <command>VACUUM</command> and <command>ANALYZE</command>
once a day during a low-usage time of day.
</para>
<para>
Unlike <xref linkend="sql-vacuum" endterm="sql-vacuum-title">,
<command>ANALYZE</command> requires
only a read lock on the target table, so it can run in parallel with
other activity on the table.
</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 may result in small changes in the planner's
estimated costs shown by <command>EXPLAIN</command>.
</para>
<para>
The collected statistics 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 may be omitted if
<command>ANALYZE</command> deems them uninteresting (for example, in
a unique-key column, there are no common values) or if the column
datatype does not support the appropriate operators.
</para>
<para>
The extent of analysis can be controlled by adjusting the per-column
statistics target with <command>ALTER TABLE ALTER COLUMN SET
STATISTICS</command> (see
<xref linkend="sql-altertable" endterm="sql-altertable-title">). 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 10, 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 may be useful to do that for columns that
are never used as part of the WHERE, GROUP BY, or ORDER BY 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>
</refsect2>
</refsect1>
<refsect1 id="R1-SQL-ANALYZE-3">
<title>
Compatibility
</title>
<refsect2 id="R2-SQL-ANALYZE-4">
<refsect2info>
<date>2001-05-04</date>
</refsect2info>
<title>
SQL92
</title>
<para>
There is no <command>ANALYZE</command> statement in <acronym>SQL92</acronym>.
</para>
</refsect2>
</refsect1>
</refentry>
<!-- Keep this comment at the end of the file
Local variables:
mode: sgml
sgml-omittag:nil
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"../reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:"/usr/lib/sgml/catalog"
sgml-local-ecat-files:nil
End:
-->

View File

@@ -1,5 +1,5 @@
<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/vacuum.sgml,v 1.13 2001/01/13 23:58:55 petere Exp $
$Header: /cvsroot/pgsql/doc/src/sgml/ref/vacuum.sgml,v 1.14 2001/05/07 00:43:15 tgl Exp $
Postgres documentation
-->
@@ -15,15 +15,15 @@ Postgres documentation
VACUUM
</refname>
<refpurpose>
Clean and analyze a <productname>Postgres</productname> database
Clean and optionally analyze a <productname>Postgres</productname> database
</refpurpose>
</refnamediv>
<refsynopsisdiv>
<refsynopsisdivinfo>
<date>1999-07-20</date>
<date>2001-05-04</date>
</refsynopsisdivinfo>
<synopsis>
VACUUM [ VERBOSE ] [ ANALYZE ] [ <replaceable class="PARAMETER">table</replaceable> ]
VACUUM [ VERBOSE ] [ <replaceable class="PARAMETER">table</replaceable> ]
VACUUM [ VERBOSE ] ANALYZE [ <replaceable class="PARAMETER">table</replaceable> [ (<replaceable class="PARAMETER">column</replaceable> [, ...] ) ] ]
</synopsis>
@@ -49,7 +49,7 @@ VACUUM [ VERBOSE ] ANALYZE [ <replaceable class="PARAMETER">table</replaceable>
<term>ANALYZE</term>
<listitem>
<para>
Updates column statistics used by the optimizer to
Updates statistics used by the optimizer to
determine the most efficient way to execute a query.
</para>
</listitem>
@@ -90,7 +90,7 @@ VACUUM [ VERBOSE ] ANALYZE [ <replaceable class="PARAMETER">table</replaceable>
</computeroutput></term>
<listitem>
<para>
The command has been accepted and the database is being cleaned.
The command is complete.
</para>
</listitem>
</varlistentry>
@@ -144,28 +144,26 @@ NOTICE: Index <replaceable class="PARAMETER">index</replaceable>: Pages 28;
Description
</title>
<para>
<command>VACUUM</command> serves two purposes in
<productname>Postgres</productname> as both a means to reclaim storage and
also a means to collect information for the optimizer.
<command>VACUUM</command> reclaims storage occupied by deleted tuples.
In normal <productname>Postgres</productname> operation, tuples that
are DELETEd or obsoleted by UPDATE are not physically removed from
their table; they remain present until a <command>VACUUM</command> is
done. Therefore it's necessary to do <command>VACUUM</command>
periodically, especially on frequently-updated tables.
</para>
<para>
<command>VACUUM</command> opens every table in the database,
cleans out records from rolled back transactions, and updates statistics in the
system catalogs. The statistics maintained include the number of
tuples and number of pages stored in all tables.
</para>
<para>
<command>VACUUM ANALYZE</command> collects statistics representing the
dispersion of the data in each column.
This information is valuable when several query execution paths are possible.
With no parameter, <command>VACUUM</command> processes every table in the
current database. With a parameter, <command>VACUUM</command> processes
only that table.
</para>
<para>
Running <command>VACUUM</command>
periodically will increase the speed of the database in processing user queries.
<command>VACUUM ANALYZE</command> performs a <command>VACUUM</command>
and then an <command>ANALYZE</command> for each selected table. This
is a handy combination form for routine maintenance scripts. See
<xref linkend="sql-analyze" endterm="sql-analyze-title">
for more details about its processing.
</para>
<refsect2 id="R2-SQL-VACUUM-3">
@@ -175,16 +173,15 @@ NOTICE: Index <replaceable class="PARAMETER">index</replaceable>: Pages 28;
<title>
Notes
</title>
<para>
The open database is the target for <command>VACUUM</command>.
</para>
<para>
We recommend that active production databases be
<command>VACUUM</command>-ed nightly, in order to remove
expired rows. After copying a large table into
<productname>Postgres</productname> or after deleting a large number
of records, it may be a good idea to issue a <command>VACUUM
ANALYZE</command> query. This will update the system catalogs with
ANALYZE</command> command for the affected table. This will update the
system catalogs with
the results of all recent changes, and allow the
<productname>Postgres</productname> query optimizer to make better
choices in planning user queries.