Sophie

Sophie

distrib > Mandriva > current > i586 > media > main-updates > by-pkgid > fc62ce67f262cdcd253dc7f849ce3223 > files > 686

postgresql8.4-docs-8.4.12-0.1mdv2010.2.i586.rpm

<!DOCTYPE HTML PUBLIC "-//W3C//DTD HTML 4.01 Transitional//EN" "http://www.w3.org/TR/html4/loose.dtd">
<HTML
><HEAD
><TITLE
>Routine Vacuuming</TITLE
><META
NAME="GENERATOR"
CONTENT="Modular DocBook HTML Stylesheet Version 1.79"><LINK
REV="MADE"
HREF="mailto:pgsql-docs@postgresql.org"><LINK
REL="HOME"
TITLE="PostgreSQL 8.4.12 Documentation"
HREF="index.html"><LINK
REL="UP"
TITLE="Routine Database Maintenance Tasks"
HREF="maintenance.html"><LINK
REL="PREVIOUS"
TITLE="Routine Database Maintenance Tasks"
HREF="maintenance.html"><LINK
REL="NEXT"
TITLE="Routine Reindexing"
HREF="routine-reindex.html"><LINK
REL="STYLESHEET"
TYPE="text/css"
HREF="stylesheet.css"><META
HTTP-EQUIV="Content-Type"
CONTENT="text/html; charset=ISO-8859-1"><META
NAME="creation"
CONTENT="2012-05-31T23:30:11"></HEAD
><BODY
CLASS="SECT1"
><DIV
CLASS="NAVHEADER"
><TABLE
SUMMARY="Header navigation table"
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TH
COLSPAN="5"
ALIGN="center"
VALIGN="bottom"
>PostgreSQL 8.4.12 Documentation</TH
></TR
><TR
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
HREF="maintenance.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="10%"
ALIGN="left"
VALIGN="top"
><A
HREF="maintenance.html"
>Fast Backward</A
></TD
><TD
WIDTH="60%"
ALIGN="center"
VALIGN="bottom"
>Chapter 23. Routine Database Maintenance Tasks</TD
><TD
WIDTH="10%"
ALIGN="right"
VALIGN="top"
><A
HREF="maintenance.html"
>Fast Forward</A
></TD
><TD
WIDTH="10%"
ALIGN="right"
VALIGN="top"
><A
HREF="routine-reindex.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
></TABLE
><HR
ALIGN="LEFT"
WIDTH="100%"></DIV
><DIV
CLASS="SECT1"
><H1
CLASS="SECT1"
><A
NAME="ROUTINE-VACUUMING"
>23.1. Routine Vacuuming</A
></H1
><A
NAME="AEN30188"
></A
><P
>   <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> databases require periodic
   maintenance known as <I
CLASS="FIRSTTERM"
>vacuuming</I
>.  For many installations, it
   is sufficient to let vacuuming be performed by the <I
CLASS="FIRSTTERM"
>autovacuum
   daemon</I
>, which is described in <A
HREF="routine-vacuuming.html#AUTOVACUUM"
>Section 23.1.5</A
>.  You might
   need to adjust the autovacuuming parameters described there to obtain best
   results for your situation.  Some database administrators will want to
   supplement or replace the daemon's activities with manually-managed
   <TT
CLASS="COMMAND"
>VACUUM</TT
> commands, which typically are executed according to a
   schedule by <SPAN
CLASS="APPLICATION"
>cron</SPAN
> or <SPAN
CLASS="APPLICATION"
>Task
   Scheduler</SPAN
> scripts.  To set up manually-managed vacuuming properly,
   it is essential to understand the issues discussed in the next few
   subsections.  Administrators who rely on autovacuuming may still wish
   to skim this material to help them understand and adjust autovacuuming.
  </P
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="VACUUM-BASICS"
>23.1.1. Vacuuming Basics</A
></H2
><P
>    <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
>'s
    <A
HREF="sql-vacuum.html"
><I
>VACUUM</I
></A
> command has to
    process each table on a regular basis for several reasons:

    <P
></P
></P><OL
TYPE="1"
><LI
><P
>To recover or reuse disk space occupied by updated or deleted
      rows.</P
></LI
><LI
><P
>To update data statistics used by the
      <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> query planner.</P
></LI
><LI
><P
>To protect against loss of very old data due to
      <I
CLASS="FIRSTTERM"
>transaction ID wraparound</I
>.</P
></LI
></OL
><P>

    Each of these reasons dictates performing <TT
CLASS="COMMAND"
>VACUUM</TT
> operations
    of varying frequency and scope, as explained in the following subsections.
   </P
><P
>    There are two variants of <TT
CLASS="COMMAND"
>VACUUM</TT
>: standard <TT
CLASS="COMMAND"
>VACUUM</TT
>
    and <TT
CLASS="COMMAND"
>VACUUM FULL</TT
>.  <TT
CLASS="COMMAND"
>VACUUM FULL</TT
> can reclaim more
    disk space but runs much more slowly.  Also,
    the standard form of <TT
CLASS="COMMAND"
>VACUUM</TT
> can run in parallel with production
    database operations.  (Commands such as <TT
CLASS="COMMAND"
>SELECT</TT
>,
    <TT
CLASS="COMMAND"
>INSERT</TT
>, <TT
CLASS="COMMAND"
>UPDATE</TT
>, and
    <TT
CLASS="COMMAND"
>DELETE</TT
> will continue to function as normal, though you
    will not be able to modify the definition of a table with commands such as
    <TT
CLASS="COMMAND"
>ALTER TABLE</TT
> while it is being vacuumed.)
    <TT
CLASS="COMMAND"
>VACUUM FULL</TT
> requires exclusive lock on the table it is
    working on, and therefore cannot be done in parallel with other use
    of the table.  Another disadvantage of <TT
CLASS="COMMAND"
>VACUUM FULL</TT
> is that
    while it reduces table size, it does not reduce index size proportionally;
    in fact it can make indexes <SPAN
CLASS="emphasis"
><I
CLASS="EMPHASIS"
>larger</I
></SPAN
>.  Generally, therefore,
    administrators should strive to use standard <TT
CLASS="COMMAND"
>VACUUM</TT
> and
    avoid <TT
CLASS="COMMAND"
>VACUUM FULL</TT
>.
   </P
><P
>    <TT
CLASS="COMMAND"
>VACUUM</TT
> creates 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
    <A
HREF="runtime-config-resource.html#RUNTIME-CONFIG-RESOURCE-VACUUM-COST"
>Section 18.4.3</A
>.
   </P
></DIV
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="VACUUM-FOR-SPACE-RECOVERY"
>23.1.2. Recovering Disk Space</A
></H2
><A
NAME="AEN30234"
></A
><P
>    In <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
>, an
    <TT
CLASS="COMMAND"
>UPDATE</TT
> or <TT
CLASS="COMMAND"
>DELETE</TT
> of a row does not
    immediately remove the old version of the row.
    This approach is necessary to gain the benefits of multiversion
    concurrency control (see <A
HREF="mvcc.html"
>Chapter 13</A
>): the row version
    must not be deleted while it is still potentially visible to other
    transactions. But eventually, an outdated or deleted row version is no
    longer of interest to any transaction. The space it occupies must then be
    reclaimed for reuse by new rows, to avoid infinite growth of disk
    space requirements. This is done by running <TT
CLASS="COMMAND"
>VACUUM</TT
>.
   </P
><P
>    The standard form of <TT
CLASS="COMMAND"
>VACUUM</TT
> removes dead row
    versions in tables and indexes and marks the space available for
    future reuse.  However, it will not return the space to the operating
    system, except in the special case where one or more pages at the
    end of a table become entirely free and an exclusive table lock can be
    easily obtained.  In contrast, <TT
CLASS="COMMAND"
>VACUUM FULL</TT
> actively compacts
    tables by moving row versions to earlier pages.  It is thus able to
    force pages at the end of the table to become entirely free, whereupon
    it will return them to the operating system.  However, if many rows
    must be moved, this can take a long time.  Also, moving a row requires
    transiently making duplicate index entries for it (the entry pointing
    to its new location must be made before the old entry can be removed);
    so moving a lot of rows this way causes severe index bloat.
   </P
><P
>    The usual goal of routine vacuuming is to do standard <TT
CLASS="COMMAND"
>VACUUM</TT
>s
    often enough to avoid needing <TT
CLASS="COMMAND"
>VACUUM FULL</TT
>.  The
    autovacuum daemon attempts to work this way, and in fact will
    never issue <TT
CLASS="COMMAND"
>VACUUM FULL</TT
>.  In this approach, the idea
    is not to keep tables at their minimum size, but to maintain steady-state
    usage of disk space: each table occupies space equivalent to its
    minimum size plus however much space gets used up between vacuumings.
    Although <TT
CLASS="COMMAND"
>VACUUM FULL</TT
> can be used to shrink a table back
    to its minimum size and return the disk space to the operating system,
    there is not much point in this if the table will just grow again in the
    future.  Thus, moderately-frequent standard <TT
CLASS="COMMAND"
>VACUUM</TT
> runs are a
    better approach than infrequent <TT
CLASS="COMMAND"
>VACUUM FULL</TT
> runs for
    maintaining heavily-updated tables.
   </P
><P
>    Some administrators prefer to schedule vacuuming themselves, for example
    doing all the work at night when load is low.
    The difficulty with doing vacuuming according to a fixed schedule
    is that if a table has an unexpected spike in update activity, it may
    get bloated to the point that <TT
CLASS="COMMAND"
>VACUUM FULL</TT
> is really necessary
    to reclaim space.  Using the autovacuum daemon alleviates this problem,
    since the daemon schedules vacuuming dynamically in response to update
    activity.  It is unwise to disable the daemon completely unless you
    have an extremely predictable workload.  One possible compromise is
    to set the daemon's parameters so that it will only react to unusually
    heavy update activity, thus keeping things from getting out of hand,
    while scheduled <TT
CLASS="COMMAND"
>VACUUM</TT
>s are expected to do the bulk of the
    work when the load is typical.
   </P
><P
>    For those not using autovacuum, a typical approach is to schedule a
    database-wide <TT
CLASS="COMMAND"
>VACUUM</TT
> once a day during a low-usage period,
    supplemented by more frequent vacuuming of heavily-updated tables as
    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
    <TT
CLASS="COMMAND"
>VACUUM</TT
> each one; the program <A
HREF="app-vacuumdb.html"
><I
><I
>vacuumdb</I
></I
></A
> might be helpful.
   </P
><DIV
CLASS="TIP"
><BLOCKQUOTE
CLASS="TIP"
><P
><B
>Tip: </B
>    Neither form of <TT
CLASS="COMMAND"
>VACUUM</TT
> is entirely satisfactory when
    a table contains large numbers of dead row versions as a result of
    massive update or delete activity.  If you have such a table and
    you need to reclaim the excess disk space it occupies, the best
    way is to use <A
HREF="sql-cluster.html"
><I
>CLUSTER</I
></A
>
    or one of the table-rewriting variants of
    <A
HREF="sql-altertable.html"
><I
>ALTER TABLE</I
></A
>.
    These commands rewrite an entire new copy of the table and build
    new indexes for it.  Like <TT
CLASS="COMMAND"
>VACUUM FULL</TT
>, they require
    exclusive lock.  Note that they also temporarily use extra disk
    space, since the old copies of the table and indexes can't be
    released until the new ones are complete.  In the worst case where
    your disk is nearly full, <TT
CLASS="COMMAND"
>VACUUM FULL</TT
> may be the only
    workable alternative.
   </P
></BLOCKQUOTE
></DIV
><DIV
CLASS="TIP"
><BLOCKQUOTE
CLASS="TIP"
><P
><B
>Tip: </B
>    If you have a table whose entire contents are deleted on a periodic
    basis, consider doing it with
    <A
HREF="sql-truncate.html"
><I
>TRUNCATE</I
></A
> rather
    than using <TT
CLASS="COMMAND"
>DELETE</TT
> followed by
    <TT
CLASS="COMMAND"
>VACUUM</TT
>. <TT
CLASS="COMMAND"
>TRUNCATE</TT
> removes the
    entire content of the table immediately, without requiring a
    subsequent <TT
CLASS="COMMAND"
>VACUUM</TT
> or <TT
CLASS="COMMAND"
>VACUUM
    FULL</TT
> to reclaim the now-unused disk space.
    The disadvantage is that strict MVCC semantics are violated.
   </P
></BLOCKQUOTE
></DIV
></DIV
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="VACUUM-FOR-STATISTICS"
>23.1.3. Updating Planner Statistics</A
></H2
><A
NAME="AEN30276"
></A
><A
NAME="AEN30279"
></A
><P
>    The <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> query planner relies on
    statistical information about the contents of tables in order to
    generate good plans for queries.  These statistics are gathered by
    the <A
HREF="sql-analyze.html"
><I
>ANALYZE</I
></A
> command,
    which can be invoked by itself or
    as an optional step in <TT
CLASS="COMMAND"
>VACUUM</TT
>.  It is important to have
    reasonably accurate statistics, otherwise poor choices of plans might
    degrade database performance.
   </P
><P
>    The autovacuum daemon, if enabled, will automatically issue
    <TT
CLASS="COMMAND"
>ANALYZE</TT
> commands whenever the content of a table has
    changed sufficiently.  However, administrators might prefer to rely
    on manually-scheduled <TT
CLASS="COMMAND"
>ANALYZE</TT
> operations, particularly
    if it is known that update activity on a table will not affect the
    statistics of <SPAN
CLASS="QUOTE"
>"interesting"</SPAN
> columns.  The daemon schedules
    <TT
CLASS="COMMAND"
>ANALYZE</TT
> strictly as a function of the number of rows
    inserted or updated; it has no knowledge of whether that will lead
    to meaningful statistical changes.
   </P
><P
>    As with vacuuming for space recovery, frequent updates of statistics
    are more useful for heavily-updated tables than for seldom-updated
    ones. But even for a heavily-updated table, there might be no need for
    statistics updates if the statistical distribution of the data is
    not changing much. A simple rule of thumb is to think about how much
    the minimum and maximum values of the columns in the table change.
    For example, a <TT
CLASS="TYPE"
>timestamp</TT
> column that contains the time
    of row update will have a constantly-increasing maximum value as
    rows are added and updated; such a column will probably need more
    frequent statistics updates than, say, a column containing URLs for
    pages accessed on a website. The URL column might receive changes just
    as often, but the statistical distribution of its values probably
    changes relatively slowly.
   </P
><P
>    It is possible to run <TT
CLASS="COMMAND"
>ANALYZE</TT
> on specific tables and even
    just specific columns of a table, so the flexibility exists to update some
    statistics more frequently than others if your application requires it.
    In practice, however, it is usually best to just analyze the entire
    database, because it is a fast operation.  <TT
CLASS="COMMAND"
>ANALYZE</TT
> uses a
    statistical random sampling of the rows of a table rather than reading
    every single row.
   </P
><DIV
CLASS="TIP"
><BLOCKQUOTE
CLASS="TIP"
><P
><B
>Tip: </B
>     Although per-column tweaking of <TT
CLASS="COMMAND"
>ANALYZE</TT
> frequency might not be
     very productive, you might well find it worthwhile to do per-column
     adjustment of the level of detail of the statistics collected by
     <TT
CLASS="COMMAND"
>ANALYZE</TT
>.  Columns that are heavily used in <TT
CLASS="LITERAL"
>WHERE</TT
>
     clauses and have highly irregular data distributions might require a
     finer-grain data histogram than other columns.  See <TT
CLASS="COMMAND"
>ALTER TABLE
     SET STATISTICS</TT
>, or change the database-wide default using the <A
HREF="runtime-config-query.html#GUC-DEFAULT-STATISTICS-TARGET"
>default_statistics_target</A
> configuration parameter.
    </P
></BLOCKQUOTE
></DIV
></DIV
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="VACUUM-FOR-WRAPAROUND"
>23.1.4. Preventing Transaction ID Wraparound Failures</A
></H2
><A
NAME="AEN30304"
></A
><P
>    <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
>'s MVCC transaction semantics
    depend on being able to compare transaction ID (<ACRONYM
CLASS="ACRONYM"
>XID</ACRONYM
>)
    numbers: a row version with an insertion XID greater than the current
    transaction's XID is <SPAN
CLASS="QUOTE"
>"in the future"</SPAN
> and should not be visible
    to the current transaction.  But since transaction IDs have limited size
    (32 bits at this writing) a cluster that runs for a long time (more
    than 4 billion transactions) would suffer <I
CLASS="FIRSTTERM"
>transaction ID
    wraparound</I
>: the XID counter wraps around to zero, and all of a sudden
    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 cannot
    get at it.)  To avoid this, it is necessary to vacuum every table
    in every database at least once every two billion transactions.
   </P
><P
>    The reason that periodic vacuuming solves the problem is that
    <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> distinguishes a special XID
    <TT
CLASS="LITERAL"
>FrozenXID</TT
>.  This XID is always considered older
    than every normal XID. Normal XIDs are
    compared using modulo-2<SUP
>31</SUP
> arithmetic. This means
    that for every normal XID, there are two billion XIDs that are
    <SPAN
CLASS="QUOTE"
>"older"</SPAN
> and two billion that are <SPAN
CLASS="QUOTE"
>"newer"</SPAN
>; another
    way to say it is that the normal XID space is circular with no
    endpoint. Therefore, once a row version has been created with a particular
    normal XID, the row version will appear to be <SPAN
CLASS="QUOTE"
>"in the past"</SPAN
> for
    the next two billion transactions, no matter which normal XID we are
    talking about. If the row version still exists after more than two billion
    transactions, it will suddenly appear to be in the future. To
    prevent data loss, old row versions must be reassigned the XID
    <TT
CLASS="LITERAL"
>FrozenXID</TT
> sometime before they reach the
    two-billion-transactions-old mark. Once they are assigned this
    special XID, they will appear to be <SPAN
CLASS="QUOTE"
>"in the past"</SPAN
> 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 old XIDs is handled by <TT
CLASS="COMMAND"
>VACUUM</TT
>.
   </P
><P
>    <A
HREF="runtime-config-client.html#GUC-VACUUM-FREEZE-MIN-AGE"
>vacuum_freeze_min_age</A
>
    controls how old an XID value has to be before it's replaced with
    <TT
CLASS="LITERAL"
>FrozenXID</TT
>.  Larger values of this setting
    preserve transactional information longer, while smaller values increase
    the number of transactions that can elapse before the table must be
    vacuumed again.
   </P
><P
>    <TT
CLASS="COMMAND"
>VACUUM</TT
> normally skips pages that don't have any dead row
    versions, but those pages might still have row versions with old XID
    values.  To ensure all old XIDs have been replaced by
    <TT
CLASS="LITERAL"
>FrozenXID</TT
>, a scan of the whole table is needed.
    <A
HREF="runtime-config-client.html#GUC-VACUUM-FREEZE-TABLE-AGE"
>vacuum_freeze_table_age</A
> controls when
    <TT
CLASS="COMMAND"
>VACUUM</TT
> does that: a whole table sweep is forced if
    the table hasn't been fully scanned for <TT
CLASS="VARNAME"
>vacuum_freeze_table_age</TT
>
    minus <TT
CLASS="VARNAME"
>vacuum_freeze_min_age</TT
> transactions. Setting it to 0
    forces <TT
CLASS="COMMAND"
>VACUUM</TT
> to always scan all pages, effectively ignoring
    the visibility map.
   </P
><P
>    The maximum time that a table can go unvacuumed is two billion
    transactions minus the <TT
CLASS="VARNAME"
>vacuum_freeze_min_age</TT
> that was used
    when <TT
CLASS="COMMAND"
>VACUUM</TT
> last scanned the whole table.  If it were to go
    unvacuumed for longer than
    that, data loss could result.  To ensure that this does not happen,
    autovacuum is invoked on any table that might contain XIDs older than the
    age specified by the configuration parameter <A
HREF="runtime-config-autovacuum.html#GUC-AUTOVACUUM-FREEZE-MAX-AGE"
>autovacuum_freeze_max_age</A
>.  (This will happen even if
    autovacuum is otherwise disabled.)
   </P
><P
>    This implies that if a table is not otherwise vacuumed,
    autovacuum will be invoked on it approximately once every
    <TT
CLASS="VARNAME"
>autovacuum_freeze_max_age</TT
> minus
    <TT
CLASS="VARNAME"
>vacuum_freeze_min_age</TT
> 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 <TT
CLASS="VARNAME"
>autovacuum_freeze_max_age</TT
> or by decreasing
    <TT
CLASS="VARNAME"
>vacuum_freeze_min_age</TT
>.
   </P
><P
>    The effective maximum for <TT
CLASS="VARNAME"
>vacuum_freeze_table_age</TT
> is 0.95 *
    <TT
CLASS="VARNAME"
>autovacuum_freeze_max_age</TT
>; a setting higher than that will be
    capped to the maximum. A value higher than
    <TT
CLASS="VARNAME"
>autovacuum_freeze_max_age</TT
> wouldn't make sense because an
    anti-wraparound autovacuum would be triggered at that point anyway, and
    the 0.95 multiplier leaves some breathing room to run a manual
    <TT
CLASS="COMMAND"
>VACUUM</TT
> before that happens.  As a rule of thumb,
    <TT
CLASS="COMMAND"
>vacuum_freeze_table_age</TT
> should be set to a value somewhat
    below <TT
CLASS="VARNAME"
>autovacuum_freeze_max_age</TT
>, leaving enough gap so that
    a regularly scheduled <TT
CLASS="COMMAND"
>VACUUM</TT
> or an autovacuum triggered by
    normal delete and update activity is run in that window.  Setting it too
    close could lead to anti-wraparound autovacuums, even though the table
    was recently vacuumed to reclaim space, whereas lower values lead to more
    frequent whole-table scans.
   </P
><P
>    The sole disadvantage of increasing <TT
CLASS="VARNAME"
>autovacuum_freeze_max_age</TT
>
    (and <TT
CLASS="VARNAME"
>vacuum_freeze_table_age</TT
> along with it)
    is that the <TT
CLASS="FILENAME"
>pg_clog</TT
> subdirectory of the database cluster
    will take more space, because it must store the commit status for all
    transactions back to the <TT
CLASS="VARNAME"
>autovacuum_freeze_max_age</TT
> horizon.
    The commit status uses two bits per transaction, so if
    <TT
CLASS="VARNAME"
>autovacuum_freeze_max_age</TT
> has its maximum allowed value of
    a little less than two billion, <TT
CLASS="FILENAME"
>pg_clog</TT
> can be expected to
    grow to about half a gigabyte.  If this is trivial compared to your
    total database size, setting <TT
CLASS="VARNAME"
>autovacuum_freeze_max_age</TT
> to
    its maximum allowed value is recommended.  Otherwise, set it depending
    on what you are willing to allow for <TT
CLASS="FILENAME"
>pg_clog</TT
> storage.
    (The default, 200 million transactions, translates to about 50MB of
    <TT
CLASS="FILENAME"
>pg_clog</TT
> storage.)
   </P
><P
>    One disadvantage of decreasing <TT
CLASS="VARNAME"
>vacuum_freeze_min_age</TT
> is that
    it might cause <TT
CLASS="COMMAND"
>VACUUM</TT
> to do useless work: changing a table row's
    XID to <TT
CLASS="LITERAL"
>FrozenXID</TT
> 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.
   </P
><P
>    To track the age of the oldest XIDs in a database,
    <TT
CLASS="COMMAND"
>VACUUM</TT
> stores XID
    statistics in the system tables <TT
CLASS="STRUCTNAME"
>pg_class</TT
> and
    <TT
CLASS="STRUCTNAME"
>pg_database</TT
>.  In particular,
    the <TT
CLASS="STRUCTFIELD"
>relfrozenxid</TT
> column of a table's
    <TT
CLASS="STRUCTNAME"
>pg_class</TT
> row contains the freeze cutoff XID that was used
    by the last whole-table <TT
CLASS="COMMAND"
>VACUUM</TT
> for that table.  All normal
    XIDs older than this cutoff XID are guaranteed to have been replaced by
    <TT
CLASS="LITERAL"
>FrozenXID</TT
> within the table.  Similarly,
    the <TT
CLASS="STRUCTFIELD"
>datfrozenxid</TT
> column of a database's
    <TT
CLASS="STRUCTNAME"
>pg_database</TT
> row is a lower bound on the normal XIDs
    appearing in that database &mdash; it is just the minimum of the
    per-table <TT
CLASS="STRUCTFIELD"
>relfrozenxid</TT
> values within the database.
    A convenient way to
    examine this information is to execute queries such as:

</P><PRE
CLASS="PROGRAMLISTING"
>SELECT relname, age(relfrozenxid) FROM pg_class WHERE relkind = 'r';
SELECT datname, age(datfrozenxid) FROM pg_database;</PRE
><P>

    The <TT
CLASS="LITERAL"
>age</TT
> column measures the number of transactions from the
    cutoff XID to the current transaction's XID.
   </P
><P
>    <TT
CLASS="COMMAND"
>VACUUM</TT
> normally
    only scans pages that have been modified since the last vacuum, but
    <TT
CLASS="STRUCTFIELD"
>relfrozenxid</TT
> can only be advanced when the whole table is
    scanned. The whole table is scanned when <TT
CLASS="STRUCTFIELD"
>relfrozenxid</TT
> is
    more than <TT
CLASS="VARNAME"
>vacuum_freeze_table_age</TT
> transactions old, when the
    <TT
CLASS="COMMAND"
>VACUUM FREEZE</TT
> command is used, or when all pages happen to
    require vacuuming to remove dead row versions. When <TT
CLASS="COMMAND"
>VACUUM</TT
>
    scans the whole table, after it's finished <TT
CLASS="LITERAL"
>age(relfrozenxid)</TT
>
    should be a little more than the <TT
CLASS="VARNAME"
>vacuum_freeze_min_age</TT
> setting
    that was used (more by the number of transactions started since the
    <TT
CLASS="COMMAND"
>VACUUM</TT
> started).  If no whole-table-scanning <TT
CLASS="COMMAND"
>VACUUM</TT
>
    is issued on the table until <TT
CLASS="VARNAME"
>autovacuum_freeze_max_age</TT
> is
    reached, an autovacuum will soon be forced for the table.
   </P
><P
>    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:

</P><PRE
CLASS="PROGRAMLISTING"
>WARNING:  database "mydb" must be vacuumed within 177009986 transactions
HINT:  To avoid a database shutdown, execute a database-wide VACUUM in "mydb".</PRE
><P>

    (A manual <TT
CLASS="COMMAND"
>VACUUM</TT
> should fix the problem, as suggested by the
    hint; but note that the <TT
CLASS="COMMAND"
>VACUUM</TT
> must be performed by a
    superuser, else it will fail to process system catalogs and thus not
    be able to advance the database's <TT
CLASS="STRUCTFIELD"
>datfrozenxid</TT
>.)
    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:

</P><PRE
CLASS="PROGRAMLISTING"
>ERROR:  database is not accepting commands to avoid wraparound data loss in database "mydb"
HINT:  Stop the postmaster and use a standalone backend to VACUUM in "mydb".</PRE
><P>

    The 1-million-transaction safety margin exists to let the
    administrator recover without data loss, by manually executing the
    required <TT
CLASS="COMMAND"
>VACUUM</TT
> commands.  However, since the system will not
    execute commands once it has gone into the safety shutdown mode,
    the only way to do this is to stop the server and use a single-user
    backend to execute <TT
CLASS="COMMAND"
>VACUUM</TT
>.  The shutdown mode is not enforced
    by a single-user backend.  See the <A
HREF="app-postgres.html"
><SPAN
CLASS="APPLICATION"
>postgres</SPAN
></A
> reference
    page for details about using a single-user backend.
   </P
></DIV
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="AUTOVACUUM"
>23.1.5. The Autovacuum Daemon</A
></H2
><A
NAME="AEN30400"
></A
><P
>    <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> has an optional but highly
    recommended feature called <I
CLASS="FIRSTTERM"
>autovacuum</I
>,
    whose purpose is to automate the execution of
    <TT
CLASS="COMMAND"
>VACUUM</TT
> and <TT
CLASS="COMMAND"
>ANALYZE </TT
> commands.
    When enabled, autovacuum checks for
    tables that have had a large number of inserted, updated or deleted
    tuples.  These checks use the statistics collection facility;
    therefore, autovacuum cannot be used unless <A
HREF="runtime-config-statistics.html#GUC-TRACK-COUNTS"
>track_counts</A
> is set to <TT
CLASS="LITERAL"
>true</TT
>.
    In the default configuration, autovacuuming is enabled and the related
    configuration parameters are appropriately set.
   </P
><P
>    The <SPAN
CLASS="QUOTE"
>"autovacuum daemon"</SPAN
> actually consists of multiple processes.
    There is a persistent daemon process, called the
    <I
CLASS="FIRSTTERM"
>autovacuum launcher</I
>, which is in charge of starting
    <I
CLASS="FIRSTTERM"
>autovacuum worker</I
> processes for all databases. The
    launcher will distribute the work across time, attempting to start one
    worker on each database every <A
HREF="runtime-config-autovacuum.html#GUC-AUTOVACUUM-NAPTIME"
>autovacuum_naptime</A
>
    seconds. One worker will be launched for each database, with a maximum
    of <A
HREF="runtime-config-autovacuum.html#GUC-AUTOVACUUM-MAX-WORKERS"
>autovacuum_max_workers</A
> processes running at the
    same time. If there are more than
    <A
HREF="runtime-config-autovacuum.html#GUC-AUTOVACUUM-MAX-WORKERS"
>autovacuum_max_workers</A
> databases to be processed,
    the next database will be processed as soon as the first worker finishes.
    Each worker process will check each table within its database and
    execute <TT
CLASS="COMMAND"
>VACUUM</TT
> and/or <TT
CLASS="COMMAND"
>ANALYZE</TT
> as needed.
   </P
><P
>    The <A
HREF="runtime-config-autovacuum.html#GUC-AUTOVACUUM-MAX-WORKERS"
>autovacuum_max_workers</A
> setting limits how many
    workers may be running at any time. If several large tables all become
    eligible for vacuuming in a short amount of time, all autovacuum workers
    may become occupied with vacuuming those tables for a long period.
    This would result
    in other tables and databases not being vacuumed until a worker became
    available. There is not a limit on how many workers might be in a
    single database, but workers do try to avoid repeating work that has
    already been done by other workers. Note that the number of running
    workers does not count towards the <A
HREF="runtime-config-connection.html#GUC-MAX-CONNECTIONS"
>max_connections</A
> nor
    the <A
HREF="runtime-config-connection.html#GUC-SUPERUSER-RESERVED-CONNECTIONS"
>superuser_reserved_connections</A
> limits.
   </P
><P
>    Tables whose <TT
CLASS="STRUCTFIELD"
>relfrozenxid</TT
> value is more than
    <A
HREF="runtime-config-autovacuum.html#GUC-AUTOVACUUM-FREEZE-MAX-AGE"
>autovacuum_freeze_max_age</A
> transactions old are always
    vacuumed (this also applies to those tables whose freeze max age has
    been modified via storage parameters; see below).  Otherwise, if the
    number of tuples obsoleted since the last
    <TT
CLASS="COMMAND"
>VACUUM</TT
> exceeds the <SPAN
CLASS="QUOTE"
>"vacuum threshold"</SPAN
>, the
    table is vacuumed.  The vacuum threshold is defined as:
</P><PRE
CLASS="PROGRAMLISTING"
>vacuum threshold = vacuum base threshold + vacuum scale factor * number of tuples</PRE
><P>
    where the vacuum base threshold is
    <A
HREF="runtime-config-autovacuum.html#GUC-AUTOVACUUM-VACUUM-THRESHOLD"
>autovacuum_vacuum_threshold</A
>,
    the vacuum scale factor is
    <A
HREF="runtime-config-autovacuum.html#GUC-AUTOVACUUM-VACUUM-SCALE-FACTOR"
>autovacuum_vacuum_scale_factor</A
>,
    and the number of tuples is
    <TT
CLASS="STRUCTNAME"
>pg_class</TT
>.<TT
CLASS="STRUCTFIELD"
>reltuples</TT
>.
    The number of obsolete tuples is obtained from the statistics
    collector; it is a semi-accurate count updated by each
    <TT
CLASS="COMMAND"
>UPDATE</TT
> and <TT
CLASS="COMMAND"
>DELETE</TT
> operation.  (It
    is only semi-accurate because some information might be lost under heavy
    load.)  If the <TT
CLASS="STRUCTFIELD"
>relfrozenxid</TT
> value of the table is more
    than <TT
CLASS="VARNAME"
>vacuum_freeze_table_age</TT
> transactions old, the whole
    table is scanned to freeze old tuples and advance
    <TT
CLASS="STRUCTFIELD"
>relfrozenxid</TT
>, otherwise only pages that have been modified
    since the last vacuum are scanned.
   </P
><P
>    For analyze, a similar condition is used: the threshold, defined as:
</P><PRE
CLASS="PROGRAMLISTING"
>analyze threshold = analyze base threshold + analyze scale factor * number of tuples</PRE
><P>
    is compared to the total number of tuples inserted or updated
    since the last <TT
CLASS="COMMAND"
>ANALYZE</TT
>.
   </P
><P
>    The default thresholds and scale factors are taken from
    <TT
CLASS="FILENAME"
>postgresql.conf</TT
>, but it is possible to override them
    on a table-by-table basis; see
    <A
HREF="sql-createtable.html#SQL-CREATETABLE-STORAGE-PARAMETERS"
><I
>Storage Parameters</I
></A
> for more information.
    If a setting
    has been changed via storage parameters, that value is used; otherwise the
    global settings are used. See <A
HREF="runtime-config-autovacuum.html"
>Section 18.9</A
> for
    more details on the global settings.
   </P
><P
>    Besides the base threshold values and scale factors, there are six
    more autovacuum parameters that can be set for each table via
    storage parameters.
    The first parameter, <TT
CLASS="LITERAL"
>autovacuum_enabled</TT
>,
    can be set to <TT
CLASS="LITERAL"
>false</TT
> to instruct the autovacuum daemon
    to skip that particular table entirely.  In this case
    autovacuum will only touch the table if it must do so
    to prevent transaction ID wraparound.
    Another two parameters,
    <TT
CLASS="LITERAL"
>autovacuum_vacuum_cost_delay</TT
> and
    <TT
CLASS="LITERAL"
>autovacuum_vacuum_cost_limit</TT
>, are used to set
    table-specific values for the
    <A
HREF="runtime-config-resource.html#RUNTIME-CONFIG-RESOURCE-VACUUM-COST"
><I
>Cost-Based Vacuum Delay</I
></A
>
    feature.
    <TT
CLASS="LITERAL"
>autovacuum_freeze_min_age</TT
>,
    <TT
CLASS="LITERAL"
>autovacuum_freeze_max_age</TT
> and
    <TT
CLASS="LITERAL"
>autovacuum_freeze_table_age</TT
> are used to set
    values for <A
HREF="runtime-config-client.html#GUC-VACUUM-FREEZE-MIN-AGE"
>vacuum_freeze_min_age</A
>,
    <A
HREF="runtime-config-autovacuum.html#GUC-AUTOVACUUM-FREEZE-MAX-AGE"
>autovacuum_freeze_max_age</A
> and
    <A
HREF="runtime-config-client.html#GUC-VACUUM-FREEZE-TABLE-AGE"
>vacuum_freeze_table_age</A
> respectively.
   </P
><P
>    When multiple workers are running, the cost limit is
    <SPAN
CLASS="QUOTE"
>"balanced"</SPAN
> among all the running workers, so that the
    total impact on the system is the same, regardless of the number
    of workers actually running.
   </P
></DIV
></DIV
><DIV
CLASS="NAVFOOTER"
><HR
ALIGN="LEFT"
WIDTH="100%"><TABLE
SUMMARY="Footer navigation table"
WIDTH="100%"
BORDER="0"
CELLPADDING="0"
CELLSPACING="0"
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
><A
HREF="maintenance.html"
ACCESSKEY="P"
>Prev</A
></TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="index.html"
ACCESSKEY="H"
>Home</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
><A
HREF="routine-reindex.html"
ACCESSKEY="N"
>Next</A
></TD
></TR
><TR
><TD
WIDTH="33%"
ALIGN="left"
VALIGN="top"
>Routine Database Maintenance Tasks</TD
><TD
WIDTH="34%"
ALIGN="center"
VALIGN="top"
><A
HREF="maintenance.html"
ACCESSKEY="U"
>Up</A
></TD
><TD
WIDTH="33%"
ALIGN="right"
VALIGN="top"
>Routine Reindexing</TD
></TR
></TABLE
></DIV
></BODY
></HTML
>