VACUUM
Garbage-collects and optionally analyzes a database.
Synopsis
VACUUM [({ FULL | FREEZE | VERBOSE | ANALYZE | DISABLE_PAGE_SKIPPING | SKIP_LOCKED | INDEX_CLEANUP } [, ...])] [<table> [(<column> [, ...] )]]
VACUUM [FULL] [FREEZE] [VERBOSE] [<table>]
VACUUM [FULL] [FREEZE] [VERBOSE] ANALYZE
[<table> [(<column> [, ...] )]]
VACUUM AO_AUX_ONLY <ao_table>
Description
VACUUM
reclaims storage occupied by deleted tuples. In normal Cloudberry 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 do VACUUM
periodically, especially on frequently-updated tables.
With no parameter, VACUUM
processes every table in the current database. With a parameter, 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 and reclaims space 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. With heap tables, 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's 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 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, 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 Access Exclusive lock is taken briefly to drop the current segment file and activate the new segment file.
VACUUM FULL
does more extensive processing, including moving of tuples across blocks to try to compact the table to the minimum number of disk blocks. This form is much slower and 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 Cloudberry Database 6.0; the unparenthesized syntax is deprecated.
Important: For information on the use of
VACUUM
,VACUUM FULL
, andVACUUM ANALYZE
, see Notes.
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.
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. Usually this should only be used when a significant amount of space needs to be reclaimed from within the table.
FREEZE
Specifying FREEZE
is equivalent to performing VACUUM
with the vacuum_freeze_min_age
server configuration parameter set to zero. See Server Configuration Parameters for information about vacuum_freeze_min_age
.
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. Furthermore, 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 vacuum_index_cleanup
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. If you use the FULL
option, it will ignore the INDEX_CLEANUP
option.
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 without any child partitions, no action takes place. If run against a heap table with an append-optimized partition, it vacuums the auxiliary tables of this partition.
<ao_table>
The name of a table to vacuum its auxiliary tables, ideally an append-optimized table.
<table>
The name (optionally schema-qualified) of a specific table to vacuum. Defaults to all tables in the current database.
<column>
The name of a specific column to analyze. Defaults to all columns. If a column list is specified, ANALYZE
is implied.
Notes
VACUUM
cannot be run inside a transaction block.
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 Cloudberry Database query optimizer to make better choices in planning queries.
Important PostgreSQL has a separate optional server process called the autovacuum daemon, whose purpose is to automate the execution of
VACUUM
andANALYZE
commands. Cloudberry Database enables the autovacuum daemon to performVACUUM
operations only on the Cloudberry Database template databasetemplate0
. Autovacuum is enabled fortemplate0
because connections are not allowed totemplate0
. The autovacuum daemon performsVACUUM
operations ontemplate0
to manage transaction IDs (XIDs) and help avoid transaction ID wraparound issues intemplate0
.
Manual VACUUM
operations must be performed in user-defined databases to manage transaction IDs (XIDs) in those databases.
VACUUM
causes a substantial increase in I/O traffic, which can cause poor performance for other active sessions. Therefore, it is advisable to vacuum the database at low usage times.
VACUUM
commands skip external and foreign tables.
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 Cloudberry 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
will usually 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.
For append-optimized tables, VACUUM
requires enough available disk space to accommodate the new segment file during the VACUUM
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.
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.