Updated on 2024-05-07 GMT+08:00

VACUUM

Description

VACUUM recycles storage space occupied by deleted rows in tables or B-Tree indexes. In normal database operation, rows that have been deleted are not physically removed from their table; they remain present until a VACUUM is done. Therefore, it is necessary to execute VACUUM periodically, especially on frequently-updated tables.

Precautions

  • If no table is specified, VACUUM processes the tables on which the user has the corresponding permission in the current database. If a table is specified, VACUUM processes only the specified table.
  • To perform VACUUM operation to a table, you must be a table owner or a user granted the VACUUM permission on the table. By default, the system administrator has this permission. However, database owners are allowed to VACUUM all tables in their databases, except shared catalogs. (The restriction for shared catalogs means that a true database-wide VACUUM can only be executed by the system administrator). VACUUM skips over any tables that the calling user does not have permission to vacuum.
  • VACUUM cannot be executed inside a transaction block.
  • It is recommended that active production databases be vacuumed frequently (at least nightly), in order to remove dead rows. After adding or deleting a large number of rows, it might be a good idea to run VACUUM ANALYZE for the affected table. This will update the system catalogs with the results of all recent changes, and allow the query planner to make better choices in planning queries.
  • FULL is recommended only in special scenarios. For example, you wish to physically narrow the table to decrease the occupied disk space after deleting most rows of a table. VACUUM FULL usually shrinks a table more than VACUUM does. The FULL option does not clear indexes. You are advised to periodically run the REINDEX statement. If the physical space usage does not decrease after you run the statement, check whether there are other active transactions (that have started before you delete data transactions and not ended before you run VACUUM FULL). If there are such transactions, run this statement again when the transactions quit.
  • VACUUM causes a significant increase in I/O traffic, which may affect the performance of other active sessions. Therefore, it is sometimes advisable to use the cost-based VACUUM delay feature.
  • When VERBOSE is specified, VACUUM will print progress messages to indicate which table is currently being processed. Various statistics about the tables are printed as well.
  • When the option list is surrounded by parentheses, the options can be written in any order. If there are no brackets, the options must be given in the order displayed in the syntax.
  • VACUUM and VACUUM FULL clean up row-store table records with a delay specified by vacuum_defer_cleanup_age, that is, tuples that have just been deleted are not cleaned up immediately.
  • VACUUM ANALYZE executes a VACUUM operation and then an ANALYZE operation for each selected table. This is a handy combination form for routine maintenance scripts.
  • A plain VACUUM statement (without the FULL option) simply recycles space and makes it available for reuse. This form of statement can operate in parallel with normal reading and writing of the table, as an exclusive lock is not obtained. VACUUM FULL executes wider processing, including moving rows across blocks to compress the tables so that they occupy the minimum number of disk blocks. This form is much slower and requires an exclusive lock on each table while it is being processed.
  • A deadlock may occur when multiple VACUUM FULL statements are executed simultaneously.
  • If the xc_maintenance_mode parameter is not enabled, the VACUUM FULL operation will skip all system catalogs.
  • If you run VACUUM FULL immediately after running DELETE, the space will not be recycled. After executing DELETE, execute 1000 non-SELECT transactions, or wait for 1s and then execute one transaction. Then, run VACUUM FULL to the space.
  • During VACUUM FULL, an exclusive lock is added to the table. Therefore, you are advised not to run VACUUM FULL during peak hours. Otherwise, the lock waiting time is too long or a deadlock occurs.

Syntax

  • Recycle space and update statistics information, without requirements for keyword orders.
    VACUUM [ ( { FULL | FREEZE | VERBOSE | {ANALYZE | ANALYSE }} [,...] ) ]
        [ table_name [ (column_name [, ...] ) ] [ PARTITION ( partition_name ) | SUBPARTITION ( subpartition_name ) ] ];
  • Recycle space, without updating statistics information.
    VACUUM [ FULL [COMPACT] ] [ FREEZE ] [ VERBOSE ] [ table_name 
    [ PARTITION ( partition_name )  | SUBPARTITION ( subpartition_name ) ] ];
  • Recycle space and update statistics information, and require keywords in order.
    VACUUM [ FULL ] [ FREEZE ] [ VERBOSE ] { ANALYZE | ANALYSE } [ VERBOSE ] 
        [ table_name [ (column_name [, ...] ) ] ] [ PARTITION ( partition_name ) ];

Parameters

  • FULL

    Selects "FULL" vacuum, which can recycle more space, but takes much longer and exclusively locks the table.

    Using FULL will cause statistics missing. To collect statistics, add the keyword ANALYZE to VACUUM FULL.

  • FREEZE

    Is equivalent to running VACUUM with the vacuum_freeze_min_age parameter set to zero.

  • VERBOSE

    Prints a detailed VACUUM activity report for each table.

  • ANALYZE | ANALYSE

    Updates statistics used by the planner to determine the most efficient way to execute a query.

    VACUUM is also triggered when autovacuum is set to analyze for a Ustore partitioned table.

  • table_name

    Specifies the name (optionally schema-qualified) of a specific table to vacuum.

    Value range: name of a specific table to vacuum Defaults are all tables in the current database.

  • column_name

    Specifies the name of the column to be analyzed. This parameter must be used together with ANALYZE.

    Value range: name of the column to be analyzed Defaults are all columns.

    The mechanism of the VACUUM ANALYZE statement is to execute VACUUM and ANALYZE in sequence. Therefore, if column_name is incorrect, VACUUM may be successfully executed but ANALYZE may fail to be executed. For a partitioned table, ANALYZE may fail to be executed after VACUUM is successfully executed on a partition.

  • PARTITION

    COMPACT and PARTITION cannot be used at the same time.

  • partition_name

    Specifies the level-1 partition name of the table to be cleared. If it is left empty, all level-1 partitions are cleared.

  • subpartition_name

    Specifies the level-2 partition name of the table to be cleared. If it is left empty, all level-2 partitions are cleared.

Examples

-- Create a schema.
gaussdb=# CREATE SCHEMA tpcds;

-- Create the tpcds.reason table.
gaussdb=# CREATE TABLE tpcds.reason
(
  r_reason_sk      integer,
  r_reason_id      character(16),
  r_reason_desc    character(100)
);

-- Insert multiple records into the table.
gaussdb=# INSERT INTO tpcds.reason values(1,'AAAAAAAABAAAAAAA','reason 1'),(2,'AAAAAAAABAAAAAAA','reason 2');

-- Create an index in the tpcds.reason table.
gaussdb=# CREATE UNIQUE INDEX ds_reason_index1 ON tpcds.reason(r_reason_sk);

-- Vacuum the tpcds.reason table that has indexes.
gaussdb=# VACUUM (VERBOSE, ANALYZE) tpcds.reason;

-- Delete the index.
gaussdb=# DROP INDEX ds_reason_index1 CASCADE;
gaussdb=# DROP TABLE tpcds.reason;
gaussdb=# DROP SCHEMA tpcds CASCADE;

Suggestions

VACUUM
  • VACUUM cannot be executed inside a transaction block.
  • It is recommended that active production databases be vacuumed frequently (at least nightly), in order to remove dead rows. It is strongly recommended that you run VACUUM ANALYZE after adding or deleting a large number of records.
  • FULL is recommended only in special scenarios. For example, you wish to physically narrow the table to decrease the occupied disk space after deleting most rows of a table.