PostgreSQL databases require periodic
   maintenance known as vacuuming.  For many installations, it
   is sufficient to let vacuuming be performed by the autovacuum
   daemon, which is described in Section 25.1.6.  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
   VACUUM commands, which typically are executed according to a
   schedule by cron or Task
   Scheduler 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.
  
    PostgreSQL's
    VACUUM command has to
    process each table on a regular basis for several reasons:
    
    Each of these reasons dictates performing VACUUM operations
    of varying frequency and scope, as explained in the following subsections.
   
    There are two variants of VACUUM: standard VACUUM
    and VACUUM FULL.  VACUUM FULL can reclaim more
    disk space but runs much more slowly.  Also,
    the standard form of VACUUM can run in parallel with production
    database operations.  (Commands such as SELECT,
    INSERT, UPDATE, and
    DELETE will continue to function normally, though you
    will not be able to modify the definition of a table with commands such as
    ALTER TABLE while it is being vacuumed.)
    VACUUM FULL requires an
    ACCESS EXCLUSIVE lock on the table it is
    working on, and therefore cannot be done in parallel with other use
    of the table.  Generally, therefore,
    administrators should strive to use standard VACUUM and
    avoid VACUUM FULL.
   
    VACUUM 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 — see
    Section 20.4.4.
   
    In PostgreSQL, an
    UPDATE or DELETE 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 (MVCC, see Chapter 13): 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 unbounded growth of disk
    space requirements. This is done by running VACUUM.
   
    The standard form of VACUUM 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, VACUUM FULL actively compacts
    tables by writing a complete new version of the table file with no dead
    space.  This minimizes the size of the table, but can take a long time.
    It also requires extra disk space for the new copy of the table, until
    the operation completes.
   
    The usual goal of routine vacuuming is to do standard VACUUMs
    often enough to avoid needing VACUUM FULL.  The
    autovacuum daemon attempts to work this way, and in fact will
    never issue VACUUM FULL.  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 vacuum runs.
    Although VACUUM FULL 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 VACUUM runs are a
    better approach than infrequent VACUUM FULL runs for
    maintaining heavily-updated tables.
   
    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 VACUUM FULL 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 VACUUMs are expected to do the bulk of the
    work when the load is typical.
   
    For those not using autovacuum, a typical approach is to schedule a
    database-wide VACUUM 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
    VACUUM each one; the program vacuumdb might be helpful.
   
    Plain VACUUM may not be 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, you will need
    to use VACUUM FULL, or alternatively
    CLUSTER
    or one of the table-rewriting variants of
    ALTER TABLE.
    These commands rewrite an entire new copy of the table and build
    new indexes for it.  All these options require an
    ACCESS EXCLUSIVE lock.  Note that
    they also temporarily use extra disk space approximately equal to the size
    of the table, since the old copies of the table and indexes can't be
    released until the new ones are complete.
   
    If you have a table whose entire contents are deleted on a periodic
    basis, consider doing it with
    TRUNCATE rather
    than using DELETE followed by
    VACUUM. TRUNCATE removes the
    entire content of the table immediately, without requiring a
    subsequent VACUUM or VACUUM
    FULL to reclaim the now-unused disk space.
    The disadvantage is that strict MVCC semantics are violated.
   
    The PostgreSQL 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 ANALYZE command,
    which can be invoked by itself or
    as an optional step in VACUUM.  It is important to have
    reasonably accurate statistics, otherwise poor choices of plans might
    degrade database performance.
   
    The autovacuum daemon, if enabled, will automatically issue
    ANALYZE commands whenever the content of a table has
    changed sufficiently.  However, administrators might prefer to rely
    on manually-scheduled ANALYZE operations, particularly
    if it is known that update activity on a table will not affect the
    statistics of “interesting” columns.  The daemon schedules
    ANALYZE 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.
   
    Tuples changed in partitions and inheritance children do not trigger
    analyze on the parent table.  If the parent table is empty or rarely
    changed, it may never be processed by autovacuum, and the statistics for
    the inheritance tree as a whole won't be collected. It is necessary to
    run ANALYZE on the parent table manually in order to
    keep the statistics up to date.
   
    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 timestamp 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.
   
    It is possible to run ANALYZE 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.  ANALYZE uses a
    statistically random sampling of the rows of a table rather than reading
    every single row.
   
     Although per-column tweaking of ANALYZE frequency might not be
     very productive, you might find it worthwhile to do per-column
     adjustment of the level of detail of the statistics collected by
     ANALYZE.  Columns that are heavily used in WHERE
     clauses and have highly irregular data distributions might require a
     finer-grain data histogram than other columns.  See ALTER TABLE
     SET STATISTICS, or change the database-wide default using the default_statistics_target configuration parameter.
    
Also, by default there is limited information available about the selectivity of functions. However, if you create a statistics object or an expression index that uses a function call, useful statistics will be gathered about the function, which can greatly improve query plans that use the expression index.
     The autovacuum daemon does not issue ANALYZE commands for
     foreign tables, since it has no means of determining how often that
     might be useful.  If your queries require statistics on foreign tables
     for proper planning, it's a good idea to run manually-managed
     ANALYZE commands on those tables on a suitable schedule.
    
     The autovacuum daemon does not issue ANALYZE commands
     for partitioned tables.  Inheritance parents will only be analyzed if the
     parent itself is changed - changes to child tables do not trigger
     autoanalyze on the parent table.  If your queries require statistics on
     parent tables for proper planning, it is necessary to periodically run
     a manual ANALYZE on those tables to keep the statistics
     up to date.
    
Vacuum maintains a visibility map for each table to keep track of which pages contain only tuples that are known to be visible to all active transactions (and all future transactions, until the page is again modified). This has two purposes. First, vacuum itself can skip such pages on the next run, since there is nothing to clean up.
Second, it allows PostgreSQL to answer some queries using only the index, without reference to the underlying table. Since PostgreSQL indexes don't contain tuple visibility information, a normal index scan fetches the heap tuple for each matching index entry, to check whether it should be seen by the current transaction. An index-only scan, on the other hand, checks the visibility map first. If it's known that all tuples on the page are visible, the heap fetch can be skipped. This is most useful on large data sets where the visibility map can prevent disk accesses. The visibility map is vastly smaller than the heap, so it can easily be cached even when the heap is very large.
    VACUUM freezes a page's tuples (by processing
    the tuple header fields described in Section 73.6.1) as a way of avoiding long term
    dependencies on transaction status metadata referenced therein.
    Heap pages that only contain frozen tuples are suitable for long
    term storage.  Larger databases are often mostly comprised of cold
    data that is modified very infrequently, plus a relatively small
    amount of hot data that is updated far more frequently.
    VACUUM applies a variety of techniques that
    allow it to concentrate most of its efforts on hot data.
   
PostgreSQL's MVCC transaction semantics depend on being able to compare transaction ID (XID) numbers: a row version with an insertion XID greater than the current transaction's XID is “in the future” and should not be visible to the current transaction. But since the on-disk representation of transaction IDs is only 32-bits, the system is incapable of representing distances between any two XIDs that exceed about 2 billion transaction IDs.
     One of the purposes of periodic vacuuming is to manage the
     Transaction Id address space.  VACUUM will
     mark rows as frozen, indicating that they
     were inserted by a transaction that committed sufficiently far in
     the past that the effects of the inserting transaction are
     certain to be visible to all current and future transactions.
     There is, in effect, an infinite distance between a frozen
     transaction ID and any unfrozen transaction ID.  This allows the
     on-disk representation of transaction IDs to recycle the 32-bit
     address space efficiently.
    
     To track the age of the oldest unfrozen XIDs in a database,
     VACUUM stores XID statistics in the system
     tables pg_class and
     pg_database.  In particular, the
     relfrozenxid column of a table's
     pg_class row contains the oldest
     remaining unfrozen XID at the end of the most recent
     VACUUM.  All rows inserted by transactions
     older than this cutoff XID are guaranteed to have been frozen.
     Similarly, the datfrozenxid column of
     a database's pg_database row is a lower
     bound on the unfrozen XIDs appearing in that database — it
     is just the minimum of the per-table
     relfrozenxid values within the
     database.  A convenient way to examine this information is to
     execute queries such as:
SELECT c.oid::regclass as table_name,
       greatest(age(c.relfrozenxid),age(t.relfrozenxid)) as age
FROM pg_class c
LEFT JOIN pg_class t ON c.reltoastrelid = t.oid
WHERE c.relkind IN ('r', 'm');
SELECT datname, age(datfrozenxid) FROM pg_database;
     The age column measures the number of transactions from the
     cutoff XID to the current transaction's XID.
    
     Multixact IDs are used to support row locking by
     multiple transactions.  Since there is only limited space in a tuple
     header to store lock information, that information is encoded as
     a “multiple transaction ID”, or multixact ID for short,
     whenever there is more than one transaction concurrently locking a
     row.  Information about which transaction IDs are included in any
     particular multixact ID is stored separately in
     the pg_multixact subdirectory, and only the multixact ID
     appears in the xmax field in the tuple header.
     Like transaction IDs, multixact IDs are implemented as a 32-bit
     counter and corresponding storage.
    
     A separate relminmxid field can be
     advanced any time relfrozenxid is
     advanced.  VACUUM manages the MultiXactId
     address space by implementing rules that are analogous to the
     approach taken with Transaction IDs.  Many of the XID-based
     settings that influence VACUUM's behavior have
     direct MultiXactId analogs. A convenient way to examine
     information about the MultiXactId address space is to execute
     queries such as:
    
SELECT c.oid::regclass as table_name,
       mxid_age(c.relminmxid)
FROM pg_class c
WHERE c.relkind IN ('r', 'm');
SELECT datname, mxid_age(datminmxid) FROM pg_database;
     When VACUUM is configured to freeze more
     aggressively it will typically set the table's
     relfrozenxid and
     relminmxid fields to relatively recent
     values.  However, there can be significant variation among tables
     with varying workload characteristics.  There can even be
     variation in how relfrozenxid
     advancement takes place over time for the same table, across
     successive VACUUM operations.  Sometimes
     VACUUM will be able to advance
     relfrozenxid and
     relminmxid by relatively many
     XIDs/MXIDs despite performing relatively little freezing work.  On
     the other hand VACUUM can sometimes freeze many
     individual pages while only advancing
     relfrozenxid by as few as one or two
     XIDs (this is typically seen following bulk loading).
    
      When the VACUUM command's VERBOSE
      parameter is specified, VACUUM prints various
      statistics about the table.  This includes information about how
      relfrozenxid and
      relminmxid advanced, as well as
      information about how many pages were newly frozen.  The same
      details appear in the server log when autovacuum logging
      (controlled by log_autovacuum_min_duration)
      reports on a VACUUM operation executed by
      autovacuum.
     
     As a general rule, the design of VACUUM
     prioritizes stable and predictable performance characteristics
     over time, while still leaving some scope for freezing lazily when
     a lazy strategy is likely to avoid unnecessary work altogether.  Tables
     whose heap relation on-disk size is less than vacuum_freeze_strategy_threshold at the start of
     VACUUM will have page freezing triggered based
     on “lazy” criteria.  Freezing will only take place
     when one or more XIDs attain an age greater than vacuum_freeze_min_age, or when one or more MXIDs
     attain an age greater than vacuum_multixact_freeze_min_age.
    
     Tables that are larger than vacuum_freeze_strategy_threshold will have
     VACUUM trigger freezing for any and all pages
     that are eligible to be frozen under the lazy criteria, as well as
     pages that VACUUM considers all visible pages.
     This is the eager freezing strategy.  The design makes the soft
     assumption that larger tables will tend to consist of pages that
     will only need to be processed by VACUUM once.
     The overhead of freezing each page is expected to be slightly
     higher in the short term, but much lower in the long term, at
     least on average.  Eager freezing also limits the accumulation of
     unfrozen pages, which tends to improve performance
     stability over time.
    
     vacuum_freeze_min_age and vacuum_multixact_freeze_min_age also act as
     limits on the age of the final values that
     relfrozenxid and
     relminmxid can be set to.  Note that
     lazy strategy VACUUMs don't necessarily have to
     advance either field by any amount, but may nevertheless advance
     each field frequently in practice.
    
    PostgreSQL has an optional but highly
    recommended feature called autovacuum,
    whose purpose is to automate the execution of
    VACUUM and ANALYZE 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 track_counts is set to true.
    In the default configuration, autovacuuming is enabled and the related
    configuration parameters are appropriately set.
   
    The “autovacuum daemon” actually consists of multiple processes.
    There is a persistent daemon process, called the
    autovacuum launcher, which is in charge of starting
    autovacuum worker processes for all databases. The
    launcher will distribute the work across time, attempting to start one
    worker within each database every autovacuum_naptime
    seconds.  (Therefore, if the installation has N databases,
    a new worker will be launched every
    autovacuum_naptime/N seconds.)
    A maximum of autovacuum_max_workers worker processes
    are allowed to run at the same time. If there are more than
    autovacuum_max_workers 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 VACUUM and/or ANALYZE as needed.
    log_autovacuum_min_duration can be set to monitor
    autovacuum workers' activity.
   
If several large tables all become eligible for vacuuming in a short amount of time, all autovacuum workers might become occupied with vacuuming those tables for a long period. This would result in other tables and databases not being vacuumed until a worker becomes available. There is no 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 max_connections or superuser_reserved_connections limits.
     Tables whose relfrozenxid value is
     more than autovacuum_freeze_max_age
     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 VACUUM exceeds the
     “vacuum threshold”, the table is vacuumed.  The
     vacuum threshold is defined as:
vacuum threshold = vacuum base threshold + vacuum scale factor * number of tuples
    where the vacuum base threshold is autovacuum_vacuum_threshold, the vacuum scale
    factor is autovacuum_vacuum_scale_factor,
    and the number of tuples is
    pg_class.reltuples.
    
The table is also vacuumed if the number of tuples inserted since the last vacuum has exceeded the defined insert threshold, which is defined as:
vacuum insert threshold = vacuum base insert threshold + vacuum insert scale factor * number of tuples
     where the vacuum insert base threshold
     is autovacuum_vacuum_insert_threshold, and
     vacuum insert scale factor is autovacuum_vacuum_insert_scale_factor.  Such
     vacuums may allow portions of the table to be marked as
     all visible and also allow tuples to be
     frozen.  The number of obsolete tuples and the number of inserted
     tuples are obtained from the cumulative statistics system; it is
     a semi-accurate count updated by each UPDATE,
     DELETE and INSERT
     operation.  (It is only semi-accurate because some information
     might be lost under heavy load.)
    
For analyze, a similar condition is used: the threshold, defined as:
analyze threshold = analyze base threshold + analyze scale factor * number of tuples
     is compared to the total number of tuples inserted, updated, or
     deleted since the last ANALYZE.
    
     If no relfrozenxid-advancing
     VACUUM is issued on the table before
     autovacuum_freeze_max_age is reached, an
     anti-wraparound autovacuum will soon be launched against the
     table.  This reliably advances
     relfrozenxid when there is no other
     reason for VACUUM to run, or when a smaller
     table had VACUUM operations that lazily opted
     not to advance relfrozenxid.
    
An anti-wraparound autovacuum will also be triggered for any table whose multixact-age is greater than autovacuum_multixact_freeze_max_age. However, if the storage occupied by multixacts members exceeds 2GB, anti-wraparound vacuum might occur more often than this.
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 forty million transactions from the wraparound point:
WARNING: database "mydb" must be vacuumed within 39985967 transactions HINT: To avoid a database shutdown, execute a database-wide VACUUM in that database.
     (A manual VACUUM should fix the problem, as suggested by the
     hint; but note that the VACUUM must be performed by a
     superuser, else it will fail to process system catalogs and thus not
     be able to advance the database's datfrozenxid.)
     If these warnings are
     ignored, the system will shut down and refuse to start any new
     transactions once there are fewer than three million transactions left
     until wraparound:
ERROR: database is not accepting commands to avoid wraparound data loss in database "mydb" HINT: Stop the postmaster and vacuum that database in single-user mode.
     The three-million-transaction safety margin exists to let the
     administrator recover by manually executing the required
     VACUUM commands.  It is usually sufficient to
     allow autovacuum to finish against the table with the oldest
     relfrozenxid and/or
     relminmxid value.  The wraparound
     failsafe mechanism controlled by vacuum_failsafe_age and vacuum_multixact_failsafe_age will typically
     trigger before warning messages are first emitted.  This happens
     dynamically, in any antiwraparound autovacuum worker that is
     tasked with advancing very old table ages.  It will also happen
     during manual VACUUM operations.
    
The shutdown mode is not enforced in single-user mode, which can be useful in some disaster recovery scenarios. See the postgres reference page for details about using single-user mode.
     Partitioned tables are not processed by autovacuum.  Statistics
     should be collected by running a manual ANALYZE when it is
     first populated, and again whenever the distribution of data in its
     partitions changes significantly.
    
Temporary tables cannot be accessed by autovacuum. Therefore, appropriate vacuum and analyze operations should be performed via session SQL commands.
     The default thresholds and scale factors are taken from
     postgresql.conf, but it is possible to override them
     (and many other autovacuum control parameters) on a per-table basis; see
     Storage Parameters for more information.
     If a setting has been changed via a table's storage parameters, that value
     is used when processing that table; otherwise the global settings are
     used. See Section 20.10 for more details on
     the global settings.
    
     When multiple workers are running, the autovacuum cost delay parameters
     (see Section 20.4.4) are
     “balanced” among all the running workers, so that the
     total I/O impact on the system is the same regardless of the number
     of workers actually running.  However, any workers processing tables whose
     per-table autovacuum_vacuum_cost_delay or
     autovacuum_vacuum_cost_limit storage parameters have been set
     are not considered in the balancing algorithm.
    
     Autovacuum workers generally don't block other commands.  If a process
     attempts to acquire a lock that conflicts with the
     SHARE UPDATE EXCLUSIVE lock held by autovacuum, lock
     acquisition will interrupt the autovacuum.  For conflicting lock modes,
     see Table 13.2.  However, if the autovacuum
     is running to prevent transaction ID wraparound (i.e., the autovacuum query
     name in the pg_stat_activity view ends with
     (to prevent wraparound)), the autovacuum is not
     automatically interrupted.
    
      Regularly running commands that acquire locks conflicting with a
      SHARE UPDATE EXCLUSIVE lock (e.g., ANALYZE) can
      effectively prevent autovacuums from ever completing.