VACUUM

Garbage-collects and optionally analyzes a database.

Synopsis

VACUUM [ (<option> [, ...]) ] [<table_name> [(<column_name> [, ...] )]]
VACUUM [FULL] [FREEZE] [VERBOSE] [ANALYZE]  [<table_name> [(<column_name> [, ...] )]]
where <option> can be one of:
    FULL [ <boolean> ]
    FREEZE [ <boolean> ]
    VERBOSE [ <boolean> ]
    ANALYZE [ <boolean> ]
    DISABLE_PAGE_SKIPPING [ <boolean> ]
    SKIP_LOCKED [ <boolean> ]
    INDEX_CLEANUP [ <boolean> ]
    TRUNCATE [ <boolean> ]
    SKIP_DATABASE_STATS [ <boolean> ]
    ONLY_DATABASE_STATS [ <boolean> ]
    AO_AUX_ONLY [ <boolean> ]

Description

VACUUM reclaims storage occupied by deleted tuples. In normal Greenplum Database operation, tuples that are deleted or obsoleted by an update are not physically removed from their table; they remain present on disk until a VACUUM is done. Therefore it is necessary to perform VACUUM periodically, especially on frequently-updated tables.

When no table list is specified, VACUUM processes every table in the current database that the current user has permission to vacuum. When a table is specified, VACUUM processes only that table.

VACUUM ANALYZE performs a VACUUM and then an ANALYZE for each selected table. This is a handy combination form for routine maintenance scripts. See ANALYZE for more details about its processing.

VACUUM (without FULL) marks deleted and obsoleted data in tables and indexes for future reuse.

With heap tables, it reclaims for re-use only if 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 a table remains as is. This form of the command can operate in parallel with normal reading and writing of the table, as an exclusive lock is not obtained. However, extra space is not returned to the operating system (in most cases); it is just kept available for re-use within the same table. VACUUM FULL rewrites the entire contents of the table into a new disk file with no extra space, allowing unused space to be returned to the operating system. This form is much slower and requires an ACCESS EXCLUSIVE lock on each table while it is being processed.

With append-optimized tables, VACUUM compacts a table by first vacuuming the indexes, then compacting each segment file in turn, if applicable, and finally vacuuming auxiliary relations and updating statistics. On each segment, visible rows are copied from the current segment file to a new segment file, and then the current segment file is scheduled to be dropped and the new segment file is made available. Plain VACUUM of an append-optimized table allows scans, inserts, deletes, and updates of the table while a segment file is compacted. However, an EXCLUSIVE lock is taken briefly to drop the current segment file and activate the new segment file.

VACUUM FULL for append-optimized tables does more extensive processing, including moving of tuples across blocks to try to compact the table to the minimum number of disk blocks. However this may also happen for VACUUM (without FULL) based on how many hidden tuples there are. VACUUM FULL requires an ACCESS EXCLUSIVE lock on each table while it is being processed. The ACCESS EXCLUSIVE lock guarantees that the holder is the only transaction accessing the table in any way.

When the option list is surrounded by parentheses, the options can be written in any order. Without parentheses, options must be specified in exactly the order shown above. The parenthesized syntax was added in Greenplum Database 6.0; the unparenthesized syntax is deprecated.

Important

For more important information on the use of VACUUM, VACUUM FULL, and VACUUM ANALYZE, see Notes.

Parameters

FULL
Selects a full vacuum, which may reclaim more space, but takes much longer and exclusively locks the table. This method also requires extra disk space, since it writes a new copy of the table and doesn't release the old copy until the operation is complete. Use this only when a significant amount of space needs to be reclaimed from within the table.
FREEZE
Selects aggressive freezing of tuples. Specifying FREEZE is equivalent to performing VACUUM with the vacuum_freeze_min_age and vacuum_freeze_table_age server configuration parameter set to zero. Aggressive freezing is always performed when the table is rewritten, so this option is redundant when FULL is specified.
VERBOSE
Prints a detailed vacuum activity report for each table.
ANALYZE
Updates statistics used by the planner to determine the most efficient way to run a query.
DISABLE_PAGE_SKIPPING
Normally, VACUUM skips pages based on the visibility map. It always skips pages where all tuples are known to be frozen, and skips those where all tuples are known to be visible to all transactions except when performing an aggressive vacuum. Except when performing an aggressive vacuum, it skips some pages in order to avoid waiting for other sessions to finish using them. This option disables all page-skipping behavior, you may use this option only when the contents of the visibility map are suspect, which should happen only if there is a hardware or software issue causing database corruption.
SKIP_LOCKED
Specifies that VACUUM should not wait for any conflicting locks to be released when beginning work on a relation: if it cannot lock a relation immediately without waiting, it skips the relation. Note that even with this option, VACUUM may still block when opening the relation's indexes. Additionally, VACUUM ANALYZE may still block when acquiring sample rows from partitions, table inheritance children, and some types of foreign tables. Also, while VACUUM ordinarily processes all partitions of specified partitioned tables, this option will cause VACUUM to skip all partitions if there is a conflicting lock on the partitioned table.
INDEX_CLEANUP
Specifies that VACUUM should attempt to remove index entries pointing to dead tuples. This is normally the desired behavior and is the default unless you override it by setting the vacuum_index_cleanup server configuration parameter to false for the table you run VACUUM against. Setting this option to false may be useful when you need to make vacuum run as quickly as possible, for example, to avoid imminent transaction ID wraparound. However, if you do not perform index cleanup regularly, performance may suffer, because as the table is modified, indexes accumulate dead tuples and the table itself accumulates dead line pointers that cannot be removed until index cleanup completes. This option has no effect for tables that do not have an index and is ignored if the FULL option is specified.
TRUNCATE
Specifies that VACUUM should attempt to truncate any empty pages at the end of the table and allow the disk space for the truncated pages to be returned to the operating system. This is normally the desired behavior and is the default unless the vacuum_truncate option has been set to false for the table to be vacuumed. Setting this option to false may be useful to avoid ACCESS EXCLUSIVE lock on the table that the truncation requires. This option is ignored if the FULL option is specified.
SKIP_DATABASE_STATS
Specifies that VACUUM should skip updating the database-wide statistics about oldest unfrozen XIDs. VACUUM normally updates these statistics once at the end of the command. This operation may take a while in a database with a very large number of tables, and accomplishes nothing unless the table that had contained the oldest unfrozen XID was among those vacuumed. If multiple VACUUM commands are issued in parallel, only one of them can update the database-wide statistics at a time. Consequently, if an application intends to issue a series of many VACUUM commands, it may be helpful to set this option in all but the last such command; or set it in all the commands and separately issue VACUUM (ONLY_DATABASE_STATS) afterwards.
ONLY_DATABASE_STATS
Specifies that VACUUM do nothing except update the database-wide statistics about oldest unfrozen XIDs. When this option is specified, the <table_and_columns> list must be empty, and no other option may be enabled except VERBOSE.
AO_AUX_ONLY
Runs VACUUM against all auxiliary tables of an append-optimized table. It does not run VACUUM against the append-optimized table. If run against a non-append-optimized table with no child partitions, no action takes place. If run against a heap table with an append-optimized partition, VACUUM vacuums the auxiliary tables of this partition. You may also use AO_AUX_ONLY without specifying a table to run against all append-optimized tables in the database.
: Specifies whether the selected option should be turned on or off. You can write `TRUE`, `ON`, or `1` to enable the option, and `FALSE`, `OFF`, or `0` to deactivate it. If the boolean value is omitted, `TRUE` is assumed.
<ao_table>
The name of a table whose auxiliary tables are to be vacuumed, most often an append-optimized table.
<table_name>
The name (optionally schema-qualified) of a specific table or materialized view to vacuum. If the specified table is a partitioned table, all of its leaf partitions are vacuumed. Defaults to all tables in the current database.
<column_name>
The name of a specific column to analyze. Defaults to all columns. If a column list is specified, ANALYZE must also be specified.

Outputs

When VERBOSE is specified, VACUUM emits progress messages to indicate which table is currently being processed. Various statistics about the tables are printed as well.

Notes

To vacuum a table, one must ordinarily be the table's owner or a superuser. However, database owners are allowed to vacuum all tables in their databases, except shared catalogs. (The restriction for shared catalogs implies that a true database-wide VACUUM can only be performed by a superuser.) VACUUM skips over any tables that the calling user does not have permission to vacuum.

VACUUM cannot be run inside a transaction block.

For tables with GIN indexes, VACUUM (in any form) also completes any pending index insertions, by moving pending index entries to the appropriate places in the main GIN index structure.

Vacuum active databases frequently (at least nightly), in order to remove expired rows. After adding or deleting a large number of rows, running the VACUUM ANALYZE command for the affected table might be useful. This updates the system catalogs with the results of all recent changes, and allows the Greenplum Database query optimizer to make better choices in planning queries.

VACUUM FULL reclaims all expired row space, however it requires an exclusive lock on each table being processed, is a very expensive operation, and might take a long time to complete on large, distributed Greenplum Database tables. Perform VACUUM FULL operations during database maintenance periods.

The FULL option is not recommended for routine use, but might be useful in special cases. An example is when you have deleted or updated most of the rows in a table and would like the table to physically shrink to occupy less disk space and allow faster table scans. VACUUM FULL usuallys shrink the table more than a plain VACUUM would.

As an alternative to VACUUM FULL, you can re-create the table with a CREATE TABLE AS statement and drop the old table.

VACUUM causes a substantial increase in I/O traffic, which might cause poor performance for other active sessions. Therefore, it is sometimes advisable to use the cost-based vacuum delay.

Greenplum Database includes an autovacuum facility that you can use to automate routine vacuum maintenance. Refer to The Autovacuum Daemon PostgreSQL documentation for more information.

VACUUM commands skip external and foreign tables.

For append-optimized tables, VACUUM and VACUUM FULL require enough available disk space to accommodate the new segment file during the VACUUM or VACUUM FULL process. If the ratio of hidden rows to total rows in a segment file is less than a threshold value (10, by default), the segment file is not compacted. The threshold value can be configured with the gp_appendonly_compaction_threshold server configuration parameter. VACUUM FULL ignores the threshold and rewrites the segment file regardless of the ratio. VACUUM can be deactivated for append-optimized tables using the gp_appendonly_compaction server configuration parameter. See Server Configuration Parameters for information about the server configuration parameters.

If a concurrent serializable transaction is detected when an append-optimized table is being vacuumed, the current and subsequent segment files are not compacted. If a segment file has been compacted but a concurrent serializable transaction is detected in the transaction that drops the original segment file, the drop is skipped. This could leave one or two segment files in an "awaiting drop" state after the vacuum has completed.

For more information about concurrency control in Greenplum Database, see Routine System Maintenance Tasks in the Greenplum Database Administrator Guide.

Examples

To clean a single table onek, analyze it for the optimizer and print a detailed vacuum activity report:

VACUUM (VERBOSE, ANALYZE) onek;

Vacuum all tables in the current database:

VACUUM;

Vacuum a specific table only:

VACUUM (VERBOSE, ANALYZE) mytable;

Vacuum all tables in the current database and collect statistics for the query optimizer:

VACUUM ANALYZE;

Compatibility

There is no VACUUM statement in the SQL standard.

See Also

ANALYZE

Parent topic: SQL Commands

check-circle-line exclamation-circle-line close-line
Scroll to top icon