Updated on 2025-02-27 GMT+08:00

REINDEX

Description

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 a fill factor) for an index, and wish that the change takes full effect.

Precautions

REINDEX DATABASE and REINDEX SYSTEM cannot be executed in transaction blocks.

Syntax

  • Rebuild an ordinary index.
    1
    REINDEX { INDEX | [INTERNAL] TABLE | DATABASE | SYSTEM } name [ FORCE ];
    
  • Rebuild an index partition.
    1
    2
    REINDEX  { INDEX|  [INTERNAL] TABLE} name
        PARTITION partition_name [ FORCE  ];
    

Parameters

  • INDEX

    Rebuilds the specified index.

  • TABLE

    Rebuilds all indexes of a specified table. The TOAST table (if any) of the table is reindexed as well. If an index in the table has been invalidated by running alter unusable, the index cannot be rebuilt.

  • DATABASE

    Rebuilds all indexes within the current database.

  • SYSTEM

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

  • name

    Specifies the name of the index, table, or database whose index needs to be rebuilt. Tables and indexes can be schema-qualified.

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

  • FORCE

    Deprecated parameter. It is currently reserved for compatibility with earlier versions.

  • partition_name

    Specifies the name of the partition or index partition to be rebuilt.

    Value range:

    • If REINDEX INDEX is used, specify the name of an index partition.
    • If REINDEX TABLE is used, specify the name of a partition.
  • REINDEX DATABASE and REINDEX SYSTEM cannot be executed in transaction blocks.
  • REINDEX does not support separate operations on TOAST tables or TOAST indexes.

Examples

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
-- Create a schema.
openGauss=# CREATE SCHEMA tpcds;

-- Create the tpcds.customer table.
openGauss=# CREATE TABLE tpcds.customer
(
c_customer_sk         INTEGER        NOT NULL,
c_customer_id         CHAR(16)       NOT NULL
);

-- Insert multiple records into the table.
openGauss=# INSERT INTO tpcds.customer VALUES (1, 'AAAAAAAABAAAAAAA'),(5, 'AAAAAAAACAAAAAAA'),(10, 'AAAAAAAADAAAAAAA');

-- Create a row-store table tpcds.customer_t1 and create an index on the c_customer_sk column in the table.
openGauss=# 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);

openGauss=# CREATE INDEX tpcds_customer_index1 ON tpcds.customer_t1 (c_customer_sk);

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

-- Rebuild a single index.
openGauss=# REINDEX INDEX tpcds.tpcds_customer_index1;

-- Rebuild all indexes in the tpcds.customer_t1 table:
openGauss=# REINDEX TABLE tpcds.customer_t1;

-- Drop the tpcds.customer_t1 table.
openGauss=# DROP TABLE tpcds.customer_t1;

-- Drop the table.
openGauss=# DROP TABLE tpcds.customer;

-- Drop the schema.
openGauss=# DROP SCHEMA tpcds CASCADE;

Suggestions

  • INTERNAL TABLE

    This scenario is used for fault recovery. You are advised not to perform concurrent operations.

  • DATABASE

    You are advised not to reindex a database in a transaction.

  • SYSTEM

    You are advised not to reindex a system catalog in a transaction.