1
0
mirror of https://github.com/postgres/postgres.git synced 2025-07-30 11:03:19 +03:00

Fix recently-understood problems with handling of XID freezing, particularly

in PITR scenarios.  We now WAL-log the replacement of old XIDs with
FrozenTransactionId, so that such replacement is guaranteed to propagate to
PITR slave databases.  Also, rather than relying on hint-bit updates to be
preserved, pg_clog is not truncated until all instances of an XID are known to
have been replaced by FrozenTransactionId.  Add new GUC variables and
pg_autovacuum columns to allow management of the freezing policy, so that
users can trade off the size of pg_clog against the amount of freezing work
done.  Revise the already-existing code that forces autovacuum of tables
approaching the wraparound point to make it more bulletproof; also, revise the
autovacuum logic so that anti-wraparound vacuuming is done per-table rather
than per-database.  initdb forced because of changes in pg_class, pg_database,
and pg_autovacuum catalogs.  Heikki Linnakangas, Simon Riggs, and Tom Lane.
This commit is contained in:
Tom Lane
2006-11-05 22:42:10 +00:00
parent 10c70b8602
commit 48188e1621
43 changed files with 1284 additions and 1062 deletions

View File

@ -1,4 +1,4 @@
<!-- $PostgreSQL: pgsql/doc/src/sgml/catalogs.sgml,v 2.135 2006/10/23 18:10:30 petere Exp $ -->
<!-- $PostgreSQL: pgsql/doc/src/sgml/catalogs.sgml,v 2.136 2006/11/05 22:42:06 tgl Exp $ -->
<!--
Documentation of the system catalogs, directed toward PostgreSQL developers
-->
@ -1241,6 +1241,20 @@
<entry></entry>
<entry>Custom <varname>vacuum_cost_limit</> parameter</entry>
</row>
<row>
<entry><structfield>freeze_min_age</structfield></entry>
<entry><type>integer</type></entry>
<entry></entry>
<entry>Custom <varname>vacuum_freeze_min_age</> parameter</entry>
</row>
<row>
<entry><structfield>freeze_max_age</structfield></entry>
<entry><type>integer</type></entry>
<entry></entry>
<entry>Custom <varname>autovacuum_freeze_max_age</> parameter</entry>
</row>
</tbody>
</tgroup>
</table>
@ -1258,6 +1272,17 @@
live tuples currently estimated to be in the relation.
</para>
<para>
Also, the autovacuum daemon will perform a <command>VACUUM</> operation
to prevent transaction ID wraparound if the table's
<structname>pg_class</>.<structfield>relfrozenxid</> field attains an age
of more than <structfield>freeze_max_age</> transactions, whether the table
has been changed or not. The system will launch autovacuum to perform
such <command>VACUUM</>s even if autovacuum is otherwise disabled.
See <xref linkend="vacuum-for-wraparound"> for more about wraparound
prevention.
</para>
<para>
Any of the numerical fields can contain <literal>-1</> (or indeed
any negative value) to indicate that the system-wide default should
@ -1266,6 +1291,10 @@
<varname>autovacuum_vacuum_cost_delay</> configuration parameter,
or from <varname>vacuum_cost_delay</> if the former is set to a negative
value. The same applies to <structfield>vac_cost_limit</>.
Also, autovacuum will ignore attempts to set a per-table
freeze_max_age larger than the system-wide setting (it can only be set
smaller), and the freeze_min_age value will be limited to half the
system-wide <varname>autovacuum_freeze_max_age</> setting.
</para>
</sect1>
@ -1633,26 +1662,15 @@
</row>
<row>
<entry><structfield>relminxid</structfield></entry>
<entry><structfield>relfrozenxid</structfield></entry>
<entry><type>xid</type></entry>
<entry></entry>
<entry>
The minimum transaction ID present in all rows in this table. This
value is used to determine the database-global
<structname>pg_database</>.<structfield>datminxid</> value.
</entry>
</row>
<row>
<entry><structfield>relvacuumxid</structfield></entry>
<entry><type>xid</type></entry>
<entry></entry>
<entry>
The transaction ID that was used as cleaning point as of the last vacuum
operation. All rows inserted, updated or deleted in this table by
transactions whose IDs are below this one have been marked as known good
or deleted. This is used to determine the database-global
<structname>pg_database</>.<structfield>datvacuumxid</> value.
All transaction IDs before this one have been replaced with a permanent
(<quote>frozen</>) transaction ID in this table. This is used to track
whether the table needs to be vacuumed in order to prevent transaction
ID wraparound or to allow <literal>pg_clog</> to be shrunk. Zero
(<symbol>InvalidTransactionId</symbol>) if the relation is not a table.
</entry>
</row>
@ -2035,31 +2053,16 @@
</row>
<row>
<entry><structfield>datvacuumxid</structfield></entry>
<entry><structfield>datfrozenxid</structfield></entry>
<entry><type>xid</type></entry>
<entry></entry>
<entry>
The transaction ID that was used as cleaning point as of the last vacuum
operation. All rows inserted or deleted by transaction IDs before this one
have been marked as known good or deleted. This
is used to determine when commit-log space can be recycled.
If <symbol>InvalidTransactionId</symbol>, then the minimum is unknown and can be
determined by scanning <structname>pg_class</>.<structfield>relvacuumxid</>.
</entry>
</row>
<row>
<entry><structfield>datminxid</structfield></entry>
<entry><type>xid</type></entry>
<entry></entry>
<entry>
The minimum transaction ID present in all tables in this database.
All rows inserted by transaction IDs before this one have been
relabeled with a permanent (<quote>frozen</>) transaction ID in this
database. This is useful to check whether a database must be
vacuumed soon to avoid transaction ID wrap-around problems.
If <symbol>InvalidTransactionId</symbol>, then the minimum is unknown and can be
determined by scanning <structname>pg_class</>.<structfield>relminxid</>.
All transaction IDs before this one have been replaced with a permanent
(<quote>frozen</>) transaction ID in this database. This is used to
track whether the database needs to be vacuumed in order to prevent
transaction ID wraparound or to allow <literal>pg_clog</> to be shrunk.
It is the minimum of the per-table
<structname>pg_class</>.<structfield>relfrozenxid</> values.
</entry>
</row>

View File

@ -1,4 +1,4 @@
<!-- $PostgreSQL: pgsql/doc/src/sgml/config.sgml,v 1.93 2006/11/04 18:20:27 tgl Exp $ -->
<!-- $PostgreSQL: pgsql/doc/src/sgml/config.sgml,v 1.94 2006/11/05 22:42:07 tgl Exp $ -->
<chapter Id="runtime-config">
<title>Server Configuration</title>
@ -3217,6 +3217,28 @@ SELECT * FROM parent WHERE key = 2400;
</listitem>
</varlistentry>
<varlistentry id="guc-autovacuum-freeze-max-age" xreflabel="autovacuum_freeze_max_age">
<term><varname>autovacuum_freeze_max_age</varname> (<type>integer</type>)</term>
<indexterm>
<primary><varname>autovacuum_freeze_max_age</> configuration parameter</primary>
</indexterm>
<listitem>
<para>
Specifies the maximum age (in transactions) that a table's
<structname>pg_class</>.<structfield>relfrozenxid</> field can
attain before a <command>VACUUM</> operation is forced to prevent
transaction ID wraparound within the table. Note that the system
will launch autovacuum processes to prevent wraparound even when
autovacuum is otherwise disabled.
The default is 200000000 (200 million).
This parameter can only be set at server start, but the setting
can be reduced for individual tables by entries in
<structname>pg_autovacuum</>.
For more information see <xref linkend="vacuum-for-wraparound">.
</para>
</listitem>
</varlistentry>
<varlistentry id="guc-autovacuum-vacuum-cost-delay" xreflabel="autovacuum_vacuum_cost_delay">
<term><varname>autovacuum_vacuum_cost_delay</varname> (<type>integer</type>)</term>
<indexterm>
@ -3427,7 +3449,7 @@ SELECT * FROM parent WHERE key = 2400;
</para>
</listitem>
</varlistentry>
<varlistentry id="guc-statement-timeout" xreflabel="statement_timeout">
<term><varname>statement_timeout</varname> (<type>integer</type>)</term>
<indexterm>
@ -3444,6 +3466,26 @@ SELECT * FROM parent WHERE key = 2400;
</para>
</listitem>
</varlistentry>
<varlistentry id="guc-vacuum-freeze-min-age" xreflabel="vacuum_freeze_min_age">
<term><varname>vacuum_freeze_min_age</varname> (<type>integer</type>)</term>
<indexterm>
<primary><varname>vacuum_freeze_min_age</> configuration parameter</primary>
</indexterm>
<listitem>
<para>
Specifies the cutoff age (in transactions) that <command>VACUUM</>
should use to decide whether to replace transaction IDs with
<literal>FrozenXID</> while scanning a table.
The default is 100000000 (100 million). Although users can set this
value anywhere from zero to 1000000000, <command>VACUUM</> will
silently limit the effective value to half the value of <xref
linkend="guc-autovacuum-freeze-max-age">, so that there is not an
unreasonably short time between forced autovacuums.
For more information see <xref linkend="vacuum-for-wraparound">.
</para>
</listitem>
</varlistentry>
</variablelist>
</sect2>

View File

@ -1,4 +1,4 @@
<!-- $PostgreSQL: pgsql/doc/src/sgml/maintenance.sgml,v 1.63 2006/10/23 18:10:31 petere Exp $ -->
<!-- $PostgreSQL: pgsql/doc/src/sgml/maintenance.sgml,v 1.64 2006/11/05 22:42:07 tgl Exp $ -->
<chapter id="maintenance">
<title>Routine Database Maintenance Tasks</title>
@ -34,7 +34,7 @@
<para>
The other main category of maintenance task is periodic <quote>vacuuming</>
of the database. This activity is discussed in
<xref linkend="routine-vacuuming">. Closely related to this updating
<xref linkend="routine-vacuuming">. Closely related to this is updating
the statistics that will be used by the query planner, as discussed in
<xref linkend="vacuum-for-statistics">.
</para>
@ -95,9 +95,10 @@
will continue to function as normal, though you will not be able to modify the
definition of a table with commands such as <command>ALTER TABLE ADD COLUMN</command>
while it is being vacuumed.
Beginning in <productname>PostgreSQL</productname> 8.0, there are
configuration parameters that can be adjusted to further reduce the
performance impact of background vacuuming. See
Also, <command>VACUUM</command> requires a substantial amount of I/O
traffic, which can cause poor performance for other active sessions.
There are configuration parameters that can be adjusted to reduce the
performance impact of background vacuuming &mdash; see
<xref linkend="runtime-config-resource-vacuum-cost">.
</para>
@ -179,9 +180,9 @@
Recommended practice for most sites is to schedule a database-wide
<command>VACUUM</> once a day at a low-usage time of day,
supplemented by more frequent vacuuming of heavily-updated tables
if necessary. (Some installations with an extremely high
rate of data modification <command>VACUUM</command> busy tables as
often as once every few minutes.) If you have multiple databases
if necessary. (Some installations with extremely high update rates
vacuum their busiest tables as often as once every few minutes.)
If you have multiple databases
in a cluster, don't forget to <command>VACUUM</command> each one;
the program <xref linkend="app-vacuumdb" endterm="app-vacuumdb-title">
may be helpful.
@ -296,29 +297,15 @@
transactions that were in the past appear to be in the future &mdash; which
means their outputs become invisible. In short, catastrophic data loss.
(Actually the data is still there, but that's cold comfort if you can't
get at it.) To avoid this, it is <emphasis>necessary to vacuum every table
in every database at least once every billion transactions</emphasis>.
get at it.) To avoid this, it is necessary to vacuum every table
in every database at least once every two billion transactions.
</para>
<para>
In practice this isn't an onerous requirement, but since the
consequences of failing to meet it can be complete data loss (not
just wasted disk space or slow performance), some special provisions
have been made to help database administrators avoid disaster.
For each database in the cluster, <productname>PostgreSQL</productname>
keeps track of the time of the last database-wide <command>VACUUM</>.
When any database approaches the billion-transaction danger level,
the system begins to emit warning messages. If nothing is done, it
will eventually shut down normal operations until appropriate
manual maintenance is done. The remainder of this
section gives the details.
</para>
<para>
The new approach to XID comparison distinguishes two special XIDs,
numbers 1 and 2 (<literal>BootstrapXID</> and
<literal>FrozenXID</>). These two XIDs are always considered older
than every normal XID. Normal XIDs (those greater than 2) are
The reason that periodic vacuuming solves the problem is that
<productname>PostgreSQL</productname> distinguishes a special XID
<literal>FrozenXID</>. This XID is always considered older
than every normal XID. Normal XIDs are
compared using modulo-2<superscript>31</> arithmetic. This means
that for every normal XID, there are two billion XIDs that are
<quote>older</> and two billion that are <quote>newer</>; another
@ -333,78 +320,128 @@
two-billion-transactions-old mark. Once they are assigned this
special XID, they will appear to be <quote>in the past</> to all
normal transactions regardless of wraparound issues, and so such
row versions will be good until deleted, no matter how long that is. This
reassignment of XID is handled by <command>VACUUM</>.
row versions will be good until deleted, no matter how long that is.
This reassignment of old XIDs is handled by <command>VACUUM</>.
</para>
<para>
<command>VACUUM</>'s normal policy is to reassign <literal>FrozenXID</>
to any row version with a normal XID more than one billion transactions in the
past. This policy preserves the original insertion XID until it is not
likely to be of interest anymore. (In fact, most row versions will probably
live and die without ever being <quote>frozen</>.) With this policy,
the maximum safe interval between <command>VACUUM</> runs on any table
is exactly one billion transactions: if you wait longer, it's possible
that a row version that was not quite old enough to be reassigned last time
is now more than two billion transactions old and has wrapped around
into the future &mdash; i.e., is lost to you. (Of course, it'll reappear
after another two billion transactions, but that's no help.)
<command>VACUUM</>'s behavior is controlled by the configuration parameter
<xref linkend="guc-vacuum-freeze-min-age">: any XID older than
<varname>vacuum_freeze_min_age</> transactions is replaced by
<literal>FrozenXID</>. Larger values of <varname>vacuum_freeze_min_age</>
preserve transactional information longer, while smaller values increase
the number of transactions that can elapse before the table must be
vacuumed again.
</para>
<para>
Since periodic <command>VACUUM</> runs are needed anyway for the reasons
described earlier, it's unlikely that any table would not be vacuumed
for as long as a billion transactions. But to help administrators ensure
this constraint is met, <command>VACUUM</> stores transaction ID
statistics in the system table <literal>pg_database</>. In particular,
the <literal>datfrozenxid</> column of a database's
<literal>pg_database</> row is updated at the completion of any
database-wide <command>VACUUM</command> operation (i.e.,
<command>VACUUM</> that does not
name a specific table). The value stored in this field is the freeze
cutoff XID that was used by that <command>VACUUM</> command. All normal
The maximum time that a table can go unvacuumed is two billion
transactions minus the <varname>vacuum_freeze_min_age</> that was used
when it was last vacuumed.
If it were to go unvacuumed for longer than that,
data loss could result. To ensure that this does not
happen, the <firstterm>autovacuum</> facility described in
<xref linkend="autovacuum"> is invoked on any table
that might contain XIDs older than the age specified by the
configuration parameter
<xref linkend="guc-autovacuum-freeze-max-age">. (This will happen
even if autovacuum is otherwise disabled.)
</para>
<para>
This implies that if a table is not otherwise vacuumed,
autovacuum will be invoked on it approximately once every
<varname>autovacuum_freeze_max_age</> minus
<varname>vacuum_freeze_min_age</> transactions.
For tables that are regularly vacuumed for space reclamation purposes,
this is of little importance. However, for static tables
(including tables that receive inserts, but no updates or deletes),
there is no need for vacuuming for space reclamation, and so it can
be useful to try to maximize the interval between forced autovacuums
on very large static tables. Obviously one can do this either by
increasing <varname>autovacuum_freeze_max_age</> or by decreasing
<varname>vacuum_freeze_min_age</>.
</para>
<para>
The sole disadvantage of increasing <varname>autovacuum_freeze_max_age</>
is that the <filename>pg_clog</> subdirectory of the database cluster
will take more space, because it must store the commit status for all
transactions back to the <varname>autovacuum_freeze_max_age</> horizon.
The commit status uses two bits per transaction, so if
<varname>autovacuum_freeze_max_age</> has its maximum allowed value of
a little less than two billion, <filename>pg_clog</> can be expected to
grow to about half a gigabyte. If this is trivial compared to your
total database size, setting <varname>autovacuum_freeze_max_age</> to
its maximum allowed value is recommended. Otherwise, set it depending
on what you are willing to allow for <filename>pg_clog</> storage.
(The default, 200 million transactions, translates to about 50MB of
<filename>pg_clog</> storage.)
</para>
<para>
One disadvantage of decreasing <varname>vacuum_freeze_min_age</> is that
it may cause <command>VACUUM</> to do useless work: changing a table row's
XID to <literal>FrozenXID</> is a waste of time if the row is modified
soon thereafter (causing it to acquire a new XID). So the setting should
be large enough that rows are not frozen until they are unlikely to change
any more. Another disadvantage of decreasing this setting is
that details about exactly which transaction inserted or modified a
row will be lost sooner. This information sometimes comes in handy,
particularly when trying to analyze what went wrong after a database
failure. For these two reasons, decreasing this setting is not
recommended except for completely static tables.
</para>
<para>
To track the age of the oldest XIDs in a database,
<command>VACUUM</> stores XID
statistics in the system tables <structname>pg_class</> and
<structname>pg_database</>. In particular,
the <structfield>relfrozenxid</> column of a table's
<structname>pg_class</> row contains the freeze cutoff XID that was used
by the last <command>VACUUM</> for that table. All normal
XIDs older than this cutoff XID are guaranteed to have been replaced by
<literal>FrozenXID</> within that database. A convenient way to
examine this information is to execute the query
<literal>FrozenXID</> within the table. Similarly,
the <structfield>datfrozenxid</> column of a database's
<structname>pg_database</> row is a lower bound on the normal XIDs
appearing in that database &mdash; it is just the minimum of the
per-table <structfield>relfrozenxid</> values within the database.
A convenient way to
examine this information is to execute queries such as
<programlisting>
SELECT relname, age(relfrozenxid) FROM pg_class WHERE relkind = 'r';
SELECT datname, age(datfrozenxid) FROM pg_database;
</programlisting>
The <literal>age</> column measures the number of transactions from the
cutoff XID to the current transaction's XID.
cutoff XID to the current transaction's XID. Immediately after a
<command>VACUUM</>, <literal>age(relfrozenxid)</> should be a little
more than the <varname>vacuum_freeze_min_age</> setting that was used
(more by the number of transactions started since the <command>VACUUM</>
started). If <literal>age(relfrozenxid)</> exceeds
<varname>autovacuum_freeze_max_age</>, an autovacuum will soon be forced
for the table.
</para>
<para>
With the standard freezing policy, the <literal>age</> column will start
at one billion for a freshly-vacuumed database. When the <literal>age</>
approaches two billion, the database must be vacuumed again to avoid
risk of wraparound failures. Recommended practice is to <command>VACUUM</command> each
database at least once every half-a-billion (500 million) transactions,
so as to provide plenty of safety margin. To help meet this rule,
each database-wide <command>VACUUM</> automatically delivers a warning
if there are any <literal>pg_database</> entries showing an
<literal>age</> of more than 1.5 billion transactions, for example:
If for some reason autovacuum fails to clear old XIDs from a table,
the system will begin to emit warning messages like this when the
database's oldest XIDs reach ten million transactions from the wraparound
point:
<programlisting>
play=# VACUUM;
WARNING: database "mydb" must be vacuumed within 177009986 transactions
HINT: To avoid a database shutdown, execute a full-database VACUUM in "mydb".
VACUUM
</programlisting>
</para>
<para>
If the warnings emitted by <command>VACUUM</> go ignored, then
<productname>PostgreSQL</productname> will begin to emit a warning
like the above on every transaction start once there are fewer than 10
million transactions left until wraparound. If those warnings also are
If these warnings are
ignored, the system will shut down and refuse to execute any new
transactions once there are fewer than 1 million transactions left
until wraparound:
<programlisting>
play=# select 2+2;
ERROR: database is shut down to avoid wraparound data loss in database "mydb"
HINT: Stop the postmaster and use a standalone backend to VACUUM in "mydb".
</programlisting>
@ -419,32 +456,6 @@ HINT: Stop the postmaster and use a standalone backend to VACUUM in "mydb".
page for details about using a single-user backend.
</para>
<para>
<command>VACUUM</> with the <command>FREEZE</> option uses a more
aggressive freezing policy: row versions are frozen if they are old enough
to be considered good by all open transactions. In particular, if a
<command>VACUUM FREEZE</> is performed in an otherwise-idle
database, it is guaranteed that <emphasis>all</> row versions in that
database will be frozen. Hence, as long as the database is not
modified in any way, it will not need subsequent vacuuming to avoid
transaction ID wraparound problems. This technique is used by
<command>initdb</> to prepare the <literal>template0</> database.
It should also be used to prepare any user-created databases that
are to be marked <literal>datallowconn</> = <literal>false</> in
<literal>pg_database</>, since there isn't any convenient way to
<command>VACUUM</command> a database that you can't connect to.
</para>
<warning>
<para>
A database that is marked <literal>datallowconn</> = <literal>false</>
in <literal>pg_database</> is assumed to be properly frozen; the
automatic warnings and wraparound protection shutdown do not take
such databases into account. Therefore it's up to you to ensure
you've correctly frozen a database before you mark it with
<literal>datallowconn</> = <literal>false</>.
</para>
</warning>
</sect2>
<sect2 id="autovacuum">
@ -471,19 +482,17 @@ HINT: Stop the postmaster and use a standalone backend to VACUUM in "mydb".
<para>
The autovacuum daemon, when enabled, runs every <xref
linkend="guc-autovacuum-naptime"> seconds and determines which database
to process. Any database which is close to transaction ID wraparound
is immediately processed. In this case, autovacuum issues a
database-wide <command>VACUUM</command> call, or <command>VACUUM
FREEZE</command> if it's a template database, and then terminates. If
no database fulfills this criterion, the one that was least recently
processed by autovacuum is chosen. In this case each table in
the selected database is checked, and individual <command>VACUUM</command>
or <command>ANALYZE</command> commands are issued as needed.
linkend="guc-autovacuum-naptime"> seconds. On each run, it selects
one database to process and checks each table within that database.
<command>VACUUM</command> or <command>ANALYZE</command> commands are
issued as needed.
</para>
<para>
For each table, two conditions are used to determine which operation(s)
Tables whose <structfield>relfrozenxid</> value is more than
<varname>autovacuum_freeze_max_age</> transactions old are always
vacuumed. Otherwise,
two conditions are used to determine which operation(s)
to apply. If the number of obsolete tuples since the last
<command>VACUUM</command> exceeds the <quote>vacuum threshold</quote>, the
table is vacuumed. The vacuum threshold is defined as:
@ -521,21 +530,28 @@ analyze threshold = analyze base threshold + analyze scale factor * number of tu
</para>
<para>
Besides the base threshold values and scale factors, there are three
Besides the base threshold values and scale factors, there are five
more parameters that can be set for each table in
<structname>pg_autovacuum</structname>.
The first, <structname>pg_autovacuum</>.<structfield>enabled</>,
can be set to <literal>false</literal> to instruct the autovacuum daemon
to skip that particular table entirely. In this case
autovacuum will only touch the table when it vacuums the entire database
autovacuum will only touch the table if it must do so
to prevent transaction ID wraparound.
The other two parameters, the vacuum cost delay
The next two parameters, the vacuum cost delay
(<structname>pg_autovacuum</structname>.<structfield>vac_cost_delay</structfield>)
and the vacuum cost limit
(<structname>pg_autovacuum</structname>.<structfield>vac_cost_limit</structfield>),
are used to set table-specific values for the
<xref linkend="runtime-config-resource-vacuum-cost" endterm="runtime-config-resource-vacuum-cost-title">
feature.
The last two parameters,
(<structname>pg_autovacuum</structname>.<structfield>freeze_min_age</structfield>)
and
(<structname>pg_autovacuum</structname>.<structfield>freeze_max_age</structfield>),
are used to set table-specific values for
<xref linkend="guc-vacuum-freeze-min-age"> and
<xref linkend="guc-autovacuum-freeze-max-age"> respectively.
</para>
<para>

View File

@ -1,4 +1,4 @@
<!-- $PostgreSQL: pgsql/doc/src/sgml/manage-ag.sgml,v 2.48 2006/09/16 00:30:14 momjian Exp $ -->
<!-- $PostgreSQL: pgsql/doc/src/sgml/manage-ag.sgml,v 2.49 2006/11/05 22:42:07 tgl Exp $ -->
<chapter id="managing-databases">
<title>Managing Databases</title>
@ -249,19 +249,6 @@ createdb -T template0 <replaceable>dbname</>
should always be marked with <literal>datistemplate = true</>.
</para>
<para>
After preparing a template database, or making any changes to one,
it is a good idea to perform <command>VACUUM FREEZE</> in that
database. If this is done when there are no other open transactions
in the same database, then it is guaranteed that all rows in the
database are <quote>frozen</> and will not be subject to transaction
ID wraparound problems. This is particularly important for a database
that will have <literal>datallowconn</literal> set to false, since it
will be impossible to do routine maintenance <command>VACUUM</> in
such a database.
See <xref linkend="vacuum-for-wraparound"> for more information.
</para>
<note>
<para>
<literal>template1</> and <literal>template0</> do not have any special

View File

@ -1,5 +1,5 @@
<!--
$PostgreSQL: pgsql/doc/src/sgml/ref/vacuum.sgml,v 1.42 2006/10/31 01:52:31 neilc Exp $
$PostgreSQL: pgsql/doc/src/sgml/ref/vacuum.sgml,v 1.43 2006/11/05 22:42:07 tgl Exp $
PostgreSQL documentation
-->
@ -20,8 +20,8 @@ PostgreSQL documentation
<refsynopsisdiv>
<synopsis>
VACUUM [ FULL | FREEZE ] [ VERBOSE ] [ <replaceable class="PARAMETER">table</replaceable> ]
VACUUM [ FULL | FREEZE ] [ VERBOSE ] ANALYZE [ <replaceable class="PARAMETER">table</replaceable> [ (<replaceable class="PARAMETER">column</replaceable> [, ...] ) ] ]
VACUUM [ FULL ] [ FREEZE ] [ VERBOSE ] [ <replaceable class="PARAMETER">table</replaceable> ]
VACUUM [ FULL ] [ FREEZE ] [ VERBOSE ] ANALYZE [ <replaceable class="PARAMETER">table</replaceable> [ (<replaceable class="PARAMETER">column</replaceable> [, ...] ) ] ]
</synopsis>
</refsynopsisdiv>
@ -62,21 +62,6 @@ VACUUM [ FULL | FREEZE ] [ VERBOSE ] ANALYZE [ <replaceable class="PARAMETER">ta
blocks. This form is much slower and requires an exclusive lock on each
table while it is being processed.
</para>
<para>
<literal>FREEZE</literal> is a special-purpose option that
causes tuples to be marked <quote>frozen</quote> as soon as possible,
rather than waiting until they are quite old. If this is done when there
are no other open transactions in the same database, then it is guaranteed
that all tuples in the database are <quote>frozen</> and will not be
subject to transaction ID wraparound problems, no matter how long the
database is left unvacuumed.
<literal>FREEZE</literal> is not recommended for routine use. Its only
intended usage is in connection with preparation of user-defined template
databases, or other databases that are completely read-only and will not
receive routine maintenance <command>VACUUM</> operations.
See <xref linkend="maintenance"> for details.
</para>
</refsect1>
<refsect1>
@ -98,6 +83,11 @@ VACUUM [ FULL | FREEZE ] [ VERBOSE ] ANALYZE [ <replaceable class="PARAMETER">ta
<listitem>
<para>
Selects aggressive <quote>freezing</quote> of tuples.
Specifying <literal>FREEZE</literal> is equivalent to performing
<command>VACUUM</command> with the
<xref linkend="guc-vacuum-freeze-min-age"> parameter
set to zero. The <literal>FREEZE</literal> option is deprecated and
will be removed in a future release; set the parameter instead.
</para>
</listitem>
</varlistentry>
@ -185,6 +175,13 @@ VACUUM [ FULL | FREEZE ] [ VERBOSE ] ANALYZE [ <replaceable class="PARAMETER">ta
it is sometimes advisable to use the cost-based vacuum delay feature.
See <xref linkend="runtime-config-resource-vacuum-cost"> for details.
</para>
<para>
<productname>PostgreSQL</productname> includes an <quote>autovacuum</>
facility which can automate routine vacuum maintenance. For more
information about automatic and manual vacuuming, see
<xref linkend="routine-vacuuming">.
</para>
</refsect1>
<refsect1>