• Data Warehouse Service

dws
  1. Help Center
  2. Data Warehouse Service
  3. Developer Guide
  4. SQL Reference
  5. SQL Syntax
  6. REINDEX

REINDEX

Function

REINDEX rebuilds an index using the data stored in the index's table, replacing the old copy of the index. There are several scenarios in which REINDEX can be used:

  • An index has become corrupted, and no longer contains valid data.
  • An index has become "bloated", that is, it contains many empty or nearly-empty pages.
  • You have altered a storage parameter (such as fillfactor) for an index, and wish to ensure that the change has taken full effect.

    An index build with the CONCURRENTLY option failed, leaving an "invalid" index.

Precautions

Index reconstruction of the REINDEX DATABASE or SYSTEM type cannot be performed in transaction blocks.

Syntax

  • Rebuild a general index.
    REINDEX { INDEX | TABLE | DATABASE | SYSTEM } name [ FORCE ];
  • Rebuild an index partition.
    REINDEX  { TABLE  | INDEX  } name
        PARTITION partition_name [ FORCE  ];

Parameter Description

  • INDEX

    Recreates the specified index.

  • TABLE

    Recreates all indexes of the specified table. If the table has a secondary TOAST table, that is reindexed as well.

  • DATABASE

    Recreates all indexes within the current database.

  • SYSTEM

    Recreates all indexes on system catalogs within the current database. Indexes on user tables are not processed.

  • name

    Name of the specific index, table, or database to be reindexed. Index and table names can be schema-qualified.

    NOTE:

    REINDEX DATABASE and SYSTEM can create indexes for only the current database. Therefore, name must be the same as the current database name.

  • FORCE

    This is an obsolete option. It is ignored if specified.

  • partition_name

    The name of the partition or index partition to be reindexed.

    Value range:

    • If it is REINDEX INDEX, specifying the name of an index partition;
    • If it is REINDEX TABLE, specifying the name of a partition.

Index reconstruction of the REINDEX DATABASE or SYSTEM type cannot be performed in transaction blocks.

Example

-- Create a row-store table tpcds.customer_t1 and create an index on the c_customer_sk column in the table:
CREATE TABLE tpcds.customer_t1
(
    c_customer_sk             integer               not null,
    c_customer_id             char(16)              not null,
    c_current_cdemo_sk        integer                       ,
    c_current_hdemo_sk        integer                       ,
    c_current_addr_sk         integer                       ,
    c_first_shipto_date_sk    integer                       ,
    c_first_sales_date_sk     integer                       ,
    c_salutation              char(10)                      ,
    c_first_name              char(20)                      ,
    c_last_name               char(30)                      ,
    c_preferred_cust_flag     char(1)                       ,
    c_birth_day               integer                       ,
    c_birth_month             integer                       ,
    c_birth_year              integer                       ,
    c_birth_country           varchar(20)                   ,
    c_login                   char(13)                      ,
    c_email_address           char(50)                      ,
    c_last_review_date        char(10)
)
WITH (orientation = row)
DISTRIBUTE BY HASH (c_customer_sk);

CREATE INDEX tpcds_customer_index1 ON tpcds.customer_t1 (c_customer_sk);

INSERT INTO tpcds.customer_t1 SELECT * FROM tpcds.customer WHERE c_customer_sk < 10;

-- Rebuild a single index.
REINDEX INDEX tpcds.tpcds_customer_index1;

-- Rebuild all indexes on the tpcds.customer_t1 table:
REINDEX TABLE tpcds.customer_t1;

-- Delete the tpcds.customer_t1 table:
DROP TABLE tpcds.customer_t1;