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

CLUSTER

Description

  • Clusters a table based on an index.
  • CLUSTER instructs GaussDB to cluster the table specified by table_name based on the index specified by index_name. The index must have been defined by table_name.
  • When a table is clustered, it is physically reordered based on the index information. Clustering is a one-time operation. When the table is subsequently updated, the changes are not clustered. That is, no attempt is performed to store new or updated rows according to their index order.
  • When a table is clustered, GaussDB records which index the table was clustered by. CLUSTER table_name reclusters the clustered index that was previously recorded in the table. You can also use ALTER TABLE table_name CLUSTER on index_name to set the index of a specified table for subsequent cluster operations, or use ALTER TABLE table_name SET WITHOUT CLUSTER to clear the previously clustered index of a specified table.
  • CLUSTER without any parameter reclusters all the previously-clustered tables in the current database that the calling user owns, or all such tables if called by an administrator.
  • When a table is being clustered, an ACCESS EXCLUSIVE lock is acquired on it. This prevents any other database operations (both read and write) from being performed on the table until the CLUSTER is finished.

Precautions

  • Only row-store B-tree indexes support CLUSTER.
  • In the case where you are accessing single rows randomly within a table, the actual order of the data in the table is unimportant. However, if there are many accesses to some data and an index groups the data, using the CLUSTER index improves performance.
  • If an index you request from a table is a range, or a single indexed value that has multiple rows that match, CLUSTER will help because once the index identifies the table page for the first row that matches, all other rows that match are probably already on the same table page, and so you save disk accesses and speed up the query.
  • During clustering, the system creates a temporary backup of the table created in the index sequence and a temporary backup of each index in the table. Therefore, ensure that the disk has sufficient free space during clustering, which is at least the sum of the table size and all index sizes.
  • CLUSTER records which indexes have been used for clustering. Therefore, you can manually specify indexes for the first time, cluster specified tables, and set a maintenance script that will be executed periodically. You only need to run the CLUSTER command without parameters. In this way, tables that you want to periodically cluster can be automatically updated.
  • The optimizer records table clustering statistics. After clustering a table, you need to execute the ANALYZE operation to ensure that the optimizer has the latest clustering information. Otherwise, the optimizer may select a non-optimal query plan.
  • CLUSTER cannot be executed in transactions.
  • If the xc_maintenance_mode parameter is not enabled, the CLUSTER operation will skip all system catalogs.

Syntax

  • Cluster a table.
    CLUSTER [ VERBOSE ] table_name [ USING index_name ];
  • Cluster a partition.
    CLUSTER [ VERBOSE ] table_name PARTITION ( partition_name ) [ USING index_name ];
  • Recluster a table.
    CLUSTER [ VERBOSE ];

Parameters

  • VERBOSE

    Enables the display of progress messages.

  • table_name

    Specifies the table name.

    Value range: an existing table name

  • index_name

    Specifies the index name.

    Value range: an existing index name

  • partition_name

    Specifies the partition name.

    Value range: an existing partition name

Examples

-- Create a partitioned table.
gaussdb=# CREATE TABLE tpcds.inventory_p1
(
    INV_DATE_SK               INTEGER               NOT NULL,
    INV_ITEM_SK               INTEGER               NOT NULL,
    INV_WAREHOUSE_SK          INTEGER               NOT NULL,
    INV_QUANTITY_ON_HAND      INTEGER
)
PARTITION BY RANGE(INV_DATE_SK)
(
        PARTITION P1 VALUES LESS THAN(2451179),
        PARTITION P2 VALUES LESS THAN(2451544),
        PARTITION P3 VALUES LESS THAN(2451910),
        PARTITION P4 VALUES LESS THAN(2452275),
        PARTITION P5 VALUES LESS THAN(2452640),
        PARTITION P6 VALUES LESS THAN(2453005),
        PARTITION P7 VALUES LESS THAN(MAXVALUE)
);

-- Create an index named ds_inventory_p1_index1.
gaussdb=# CREATE INDEX ds_inventory_p1_index1 ON tpcds.inventory_p1 (INV_ITEM_SK) LOCAL;

-- Cluster the tpcds.inventory_p1 table.
gaussdb=# CLUSTER tpcds.inventory_p1 USING ds_inventory_p1_index1;

-- Cluster the p3 partition.
gaussdb=# CLUSTER tpcds.inventory_p1 PARTITION (p3) USING ds_inventory_p1_index1;

-- Cluster the tables that can be clustered in the database.
gaussdb=# CLUSTER;

-- Delete the index.
gaussdb=# DROP INDEX tpcds.ds_inventory_p1_index1;

-- Drop the partitioned table.
gaussdb=# DROP TABLE tpcds.inventory_p1;

Suggestions

  • cluster
    • It is recommended that you run ANALYZE on a newly clustered table. Otherwise, the optimizer might make poor choices of query plans.
    • CLUSTER cannot be executed in transactions.