Sophie

Sophie

distrib > Mandriva > 2010.0 > i586 > media > contrib-release > by-pkgid > a866202fe868538f89a755dbcabc378b > files > 551

postgresql8.2-docs-8.2.14-1mdv2010.0.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.2.14 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="2009-09-04T05:25:47"></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.2.14 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 22. 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"
>22.1. Routine Vacuuming</A
></H1
><A
NAME="AEN24527"
></A
><P
>   <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
>'s <TT
CLASS="COMMAND"
>VACUUM</TT
> command
   <SPAN
CLASS="emphasis"
><I
CLASS="EMPHASIS"
>must</I
></SPAN
> be run 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>

   The frequency and scope of the <TT
CLASS="COMMAND"
>VACUUM</TT
> operations
   performed for each of these reasons will vary depending on the
   needs of each site.  Therefore, database administrators must
   understand these issues and develop an appropriate maintenance
   strategy.  This section concentrates on explaining the high-level
   issues; for details about command syntax and so on, see the <A
HREF="sql-vacuum.html"
><I
>VACUUM</I
></A
> reference page.
  </P
><P
>   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 ADD COLUMN</TT
>
   while it is being vacuumed.
   Also, <TT
CLASS="COMMAND"
>VACUUM</TT
> 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
   <A
HREF="runtime-config-resource.html#RUNTIME-CONFIG-RESOURCE-VACUUM-COST"
>Section 17.4.4</A
>.
  </P
><P
>   An automated mechanism for performing the necessary <TT
CLASS="COMMAND"
>VACUUM</TT
>
   operations has been added in <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> 8.1.
   See <A
HREF="routine-vacuuming.html#AUTOVACUUM"
>Section 22.1.4</A
>.
  </P
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="VACUUM-FOR-SPACE-RECOVERY"
>22.1.1. Recovering disk space</A
></H2
><A
NAME="AEN24559"
></A
><P
>    In normal <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL</SPAN
> operation, 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 12</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 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
>    Clearly, a table that receives frequent updates or deletes will need
    to be vacuumed more often than tables that are seldom updated. It
    may be useful to set up periodic <SPAN
CLASS="APPLICATION"
>cron</SPAN
> tasks that
    <TT
CLASS="COMMAND"
>VACUUM</TT
> only selected tables, skipping tables that are known not to
    change often. This is only likely to be helpful if you have both
    large heavily-updated tables and large seldom-updated tables &mdash; the
    extra cost of vacuuming a small table isn't enough to be worth
    worrying about.
   </P
><P
>    There are two variants of the <TT
CLASS="COMMAND"
>VACUUM</TT
>
    command. The first form, known as <SPAN
CLASS="QUOTE"
>"lazy vacuum"</SPAN
> or
    just <TT
CLASS="COMMAND"
>VACUUM</TT
>, marks expired data in tables and
    indexes for future reuse; it does <SPAN
CLASS="emphasis"
><I
CLASS="EMPHASIS"
>not</I
></SPAN
> attempt
    to reclaim the space used by this expired data unless the space is
    at the end of the table and an exclusive table lock can be easily 
    obtained. Unused space at the start or middle of the file does
    not result in the file being shortened and space returned to the
    operating system. This variant of <TT
CLASS="COMMAND"
>VACUUM</TT
> can be
    run concurrently with normal database operations.
   </P
><P
>    The second form is the <TT
CLASS="COMMAND"
>VACUUM FULL</TT
>
    command. This uses a more aggressive algorithm for reclaiming the
    space consumed by expired row versions. Any space that is freed by
    <TT
CLASS="COMMAND"
>VACUUM FULL</TT
> is immediately returned to the
    operating system. Unfortunately, this variant of the
    <TT
CLASS="COMMAND"
>VACUUM</TT
> command acquires an exclusive lock on
    each table while <TT
CLASS="COMMAND"
>VACUUM FULL</TT
> is processing
    it. Therefore, frequently using <TT
CLASS="COMMAND"
>VACUUM FULL</TT
> can
    have an extremely negative effect on the performance of concurrent
    database queries.
   </P
><P
>    The standard form of <TT
CLASS="COMMAND"
>VACUUM</TT
> is best used with the goal
    of maintaining a fairly level steady-state usage of disk space. If
    you need to return disk space to the operating system you can use
    <TT
CLASS="COMMAND"
>VACUUM FULL</TT
> &mdash; but what's the point of releasing disk
    space that will only have to be allocated again soon?  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
>    Recommended practice for most sites is to schedule a database-wide
    <TT
CLASS="COMMAND"
>VACUUM</TT
> once a day at a low-usage time of day,
    supplemented by more frequent vacuuming of heavily-updated tables
    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 <TT
CLASS="COMMAND"
>VACUUM</TT
> each one;
    the program <A
HREF="app-vacuumdb.html"
><I
><I
>vacuumdb</I
></I
></A
>
    may be helpful.
   </P
><P
>    <TT
CLASS="COMMAND"
>VACUUM FULL</TT
> is recommended for cases where you know
    you have deleted the majority of rows in a table, so that the
    steady-state size of the table can be shrunk substantially with
    <TT
CLASS="COMMAND"
>VACUUM FULL</TT
>'s more aggressive approach.  Use plain
    <TT
CLASS="COMMAND"
>VACUUM</TT
>, not <TT
CLASS="COMMAND"
>VACUUM FULL</TT
>, for routine
    vacuuming for space recovery.
   </P
><P
>    If you have a table whose entire contents are deleted on a periodic
    basis, consider doing it with <TT
CLASS="COMMAND"
>TRUNCATE</TT
> 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.
   </P
></DIV
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="VACUUM-FOR-STATISTICS"
>22.1.2. Updating planner statistics</A
></H2
><A
NAME="AEN24605"
></A
><A
NAME="AEN24608"
></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 <TT
CLASS="COMMAND"
>ANALYZE</TT
> 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 may
    degrade database performance.
   </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 may 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 may 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.  It 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 may not be
     very productive, you may 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 may require a finer-grain
     data histogram than other columns.  See <TT
CLASS="COMMAND"
>ALTER TABLE SET
     STATISTICS</TT
>.
    </P
></BLOCKQUOTE
></DIV
><P
>    Recommended practice for most sites is to schedule a database-wide
    <TT
CLASS="COMMAND"
>ANALYZE</TT
> once a day at a low-usage time of day; this can
    usefully be combined with a nightly <TT
CLASS="COMMAND"
>VACUUM</TT
>.  However,
    sites with relatively slowly changing table statistics may find that
    this is overkill, and that less-frequent <TT
CLASS="COMMAND"
>ANALYZE</TT
> runs
    are sufficient.
   </P
></DIV
><DIV
CLASS="SECT2"
><H2
CLASS="SECT2"
><A
NAME="VACUUM-FOR-WRAPAROUND"
>22.1.3. Preventing transaction ID wraparound failures</A
></H2
><A
NAME="AEN24630"
></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 can't
    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
>    <TT
CLASS="COMMAND"
>VACUUM</TT
>'s behavior is controlled by the configuration parameter
    <A
HREF="runtime-config-client.html#GUC-VACUUM-FREEZE-MIN-AGE"
>vacuum_freeze_min_age</A
>: any XID older than
    <TT
CLASS="VARNAME"
>vacuum_freeze_min_age</TT
> transactions is replaced by
    <TT
CLASS="LITERAL"
>FrozenXID</TT
>.  Larger values of <TT
CLASS="VARNAME"
>vacuum_freeze_min_age</TT
>
    preserve transactional information longer, while smaller values increase
    the number of transactions that can elapse before the table must be
    vacuumed again.
   </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 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 <I
CLASS="FIRSTTERM"
>autovacuum</I
> facility described in
    <A
HREF="routine-vacuuming.html#AUTOVACUUM"
>Section 22.1.4</A
> 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 sole disadvantage of increasing <TT
CLASS="VARNAME"
>autovacuum_freeze_max_age</TT
>
    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 may 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 <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.  Immediately after a
    <TT
CLASS="COMMAND"
>VACUUM</TT
>, <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 <TT
CLASS="LITERAL"
>age(relfrozenxid)</TT
> exceeds
    <TT
CLASS="VARNAME"
>autovacuum_freeze_max_age</TT
>, 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 full-database VACUUM in "mydb".</PRE
><P>

    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 shut down 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"
>22.1.4. The auto-vacuum daemon</A
></H2
><A
NAME="AEN24704"
></A
><P
>    Beginning in <SPAN
CLASS="PRODUCTNAME"
>PostgreSQL </SPAN
> 8.1, there is a
    separate optional server process called the <I
CLASS="FIRSTTERM"
>autovacuum
    daemon</I
>, whose purpose is to automate the execution of
    <TT
CLASS="COMMAND"
>VACUUM</TT
> and <TT
CLASS="COMMAND"
>ANALYZE </TT
> commands.
    When enabled, the autovacuum daemon runs periodically and checks for
    tables that have had a large number of inserted, updated or deleted
    tuples.  These checks use the row-level statistics collection facility;
    therefore, the autovacuum daemon cannot be used unless <A
HREF="runtime-config-statistics.html#GUC-STATS-START-COLLECTOR"
>stats_start_collector</A
> and <A
HREF="runtime-config-statistics.html#GUC-STATS-ROW-LEVEL"
>stats_row_level</A
> are set to <TT
CLASS="LITERAL"
>true</TT
>.  Also,
    it's important to allow a slot for the autovacuum process when choosing
    the value of <A
HREF="runtime-config-connection.html#GUC-SUPERUSER-RESERVED-CONNECTIONS"
>superuser_reserved_connections</A
>.
   </P
><P
>    The autovacuum daemon, when enabled, runs every <A
HREF="runtime-config-autovacuum.html#GUC-AUTOVACUUM-NAPTIME"
>autovacuum_naptime</A
> seconds.  On each run, it selects
    one database to process and checks each table within that database.
    <TT
CLASS="COMMAND"
>VACUUM</TT
> or <TT
CLASS="COMMAND"
>ANALYZE</TT
> commands are
    issued as needed.
   </P
><P
>    Tables whose <TT
CLASS="STRUCTFIELD"
>relfrozenxid</TT
> value is more than
    <TT
CLASS="VARNAME"
>autovacuum_freeze_max_age</TT
> 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
    <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 may be lost under heavy
    load.)  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, updated, or deleted
    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 by making entries in the system catalog
    <A
HREF="catalog-pg-autovacuum.html"
><TT
CLASS="STRUCTNAME"
>pg_autovacuum</TT
></A
>.
    If a <TT
CLASS="STRUCTNAME"
>pg_autovacuum</TT
> row exists for a particular
    table, the settings it specifies are applied; otherwise the global
    settings are used.  See <A
HREF="runtime-config-autovacuum.html"
>Section 17.9</A
> for
    more details on the global settings.
   </P
><P
>    Besides the base threshold values and scale factors, there are five
    more parameters that can be set for each table in
    <TT
CLASS="STRUCTNAME"
>pg_autovacuum</TT
>.
    The first, <TT
CLASS="STRUCTNAME"
>pg_autovacuum</TT
>.<TT
CLASS="STRUCTFIELD"
>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.
    The next two parameters, the vacuum cost delay
    (<TT
CLASS="STRUCTNAME"
>pg_autovacuum</TT
>.<TT
CLASS="STRUCTFIELD"
>vac_cost_delay</TT
>)
    and the vacuum cost limit
    (<TT
CLASS="STRUCTNAME"
>pg_autovacuum</TT
>.<TT
CLASS="STRUCTFIELD"
>vac_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.
    The last two parameters,
    (<TT
CLASS="STRUCTNAME"
>pg_autovacuum</TT
>.<TT
CLASS="STRUCTFIELD"
>freeze_min_age</TT
>)
    and
    (<TT
CLASS="STRUCTNAME"
>pg_autovacuum</TT
>.<TT
CLASS="STRUCTFIELD"
>freeze_max_age</TT
>), 
    are used to set table-specific values for
    <A
HREF="runtime-config-client.html#GUC-VACUUM-FREEZE-MIN-AGE"
>vacuum_freeze_min_age</A
> and
    <A
HREF="runtime-config-autovacuum.html#GUC-AUTOVACUUM-FREEZE-MAX-AGE"
>autovacuum_freeze_max_age</A
> respectively.
   </P
><P
>    If any of the values in <TT
CLASS="STRUCTNAME"
>pg_autovacuum</TT
>
    are set to a negative number, or if a row is not present at all in
    <TT
CLASS="STRUCTNAME"
>pg_autovacuum</TT
> for any particular table, the
    corresponding values from <TT
CLASS="FILENAME"
>postgresql.conf</TT
> are used.
   </P
><P
>    There is not currently any support for making
    <TT
CLASS="STRUCTNAME"
>pg_autovacuum</TT
> entries, except by doing
    manual <TT
CLASS="COMMAND"
>INSERT</TT
>s into the catalog.  This feature will be
    improved in future releases, and it is likely that the catalog
    definition will change.
   </P
><DIV
CLASS="CAUTION"
><P
></P
><TABLE
CLASS="CAUTION"
BORDER="1"
WIDTH="100%"
><TR
><TD
ALIGN="CENTER"
><B
>Caution</B
></TD
></TR
><TR
><TD
ALIGN="LEFT"
><P
>     The contents of the <TT
CLASS="STRUCTNAME"
>pg_autovacuum</TT
> system
     catalog are currently not saved in database dumps created by
     the tools <TT
CLASS="COMMAND"
>pg_dump</TT
> and <TT
CLASS="COMMAND"
>pg_dumpall</TT
>.
     If you want to preserve them across a dump/reload cycle, make sure you
     dump the catalog manually.
    </P
></TD
></TR
></TABLE
></DIV
></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
>