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

ALTER INDEX

Description

ALTER INDEX modifies the definition of an existing index.

It has the following forms:

  • IF EXISTS

    Sends a notice instead of an error if the specified index does not exist.

  • RENAME TO

    Changes only the name of the index. The stored data is not affected.

  • SET TABLESPACE

    Changes the index tablespace to the specified tablespace and moves index-related data files to the new tablespace.

  • SET ( { STORAGE_PARAMETER = value } [, ...] )

    Changes one or more index-method-specific storage parameters of an index. Note that the index content will not be modified immediately by this statement. You may need to use REINDEX to rebuild the index based on different parameters to achieve the expected effect.

  • RESET ( { storage_parameter } [, ...] )

    Resets one or more index-method-specific storage parameters of an index to the default value. Similar to the SET statement, REINDEX may be used to completely update the index.

  • [ MODIFY PARTITION index_partition_name ] UNUSABLE

    Sets the indexes on a table or index partition to be unavailable.

  • REBUILD [ PARTITION index_partition_name ]

    Rebuilds indexes on a table or an index partition.

  • RENAME PARTITION

    Renames an index partition.

  • MOVE PARTITION

    Modifies the tablespace to which an index partition belongs.

Precautions

Only the index owner, a user who has the INDEX permission on the table where the index resides, or a user who has the ALTER ANY INDEX permission can run the ALTER INDEX command. The system administrator has this permission by default.

Syntax

  • Rename a table index.
    ALTER INDEX [ IF EXISTS ] index_name 
        RENAME TO new_name;
  • Change the tablespace to which a table index belongs.
    ALTER INDEX [ IF EXISTS ] index_name 
        SET TABLESPACE tablespace_name;
  • Modify the storage parameter of a table index.
    ALTER INDEX [ IF EXISTS ] index_name 
        SET ( {storage_parameter = value} [, ... ] );
  • Reset the storage parameter of a table index.
    ALTER INDEX [ IF EXISTS ] index_name 
        RESET ( storage_parameter [, ... ] ) ;
  • Set a table index or an index partition to be unavailable.
    ALTER INDEX [ IF EXISTS ] index_name 
        [ MODIFY PARTITION index_partition_name ] UNUSABLE;
  • Rebuild a table index or index partition.
    ALTER INDEX index_name 
        REBUILD [ PARTITION index_partition_name ];
  • Rename an index partition.
    ALTER INDEX [ IF EXISTS ] index_name 
        RENAME PARTITION index_partition_name TO new_index_partition_name;
  • Modify the tablespace to which an index partition belongs.
    ALTER INDEX [ IF EXISTS ] index_name 
        MOVE PARTITION index_partition_name TABLESPACE new_tablespace;

Parameters

  • index_name

    Specifies the index name to be modified.

  • new_name

    Specifies the new name of the index.

    Value range: a string. It must comply with the naming convention.

  • tablespace_name

    Specifies the tablespace name.

    Value range: an existing tablespace name

  • storage_parameter

    Specifies the name of an index-method-specific parameter. ACTIVE_PAGES indicates the number of index pages, which may be less than the actual number of physical file pages and can be used for optimization. Currently, this parameter is valid only for the local index of the Ustore partitioned table and will be updated by VACUUM and ANALYZE (including AUTOVACUUM). You are not advised to manually set this parameter.

  • value

    Specifies the new value for an index-method-specific storage parameter. This might be a number or a word depending on the parameter.

  • new_index_partition_name

    Specifies the new name of the index partition.

  • index_partition_name

    Specifies the name of an index partition.

  • new_tablespace

    Specifies a new tablespace.

Examples

See Examples in section "CREATE INDEX."

Helpful Links

CREATE INDEX, DROP INDEX, and REINDEX