REINDEX
Rebuilds indexes.
Synopsis
REINDEX [ (VERBOSE) ] { INDEX | TABLE | SCHEMA | DATABASE | SYSTEM } <name>
Description
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 to use REINDEX
:
- An index has become corrupted, and no longer contains valid data. Although in theory this should never happen, in practice indexes can become corrupted due to software bugs or hardware failures.
REINDEX
provides a recovery method. - An index has become bloated, that is, it contains many empty or nearly-empty pages. This can occur with B-tree indexes in Cloudberry Database under certain uncommon access patterns.
REINDEX
provides a way to reduce the space consumption of the index by writing a new version of the index without the dead pages. - You have altered a storage parameter (such as
fillfactor
) for an index, and wish to ensure that the change has taken full effect.
Parameters
INDEX
Recreate the specified index.
TABLE
Recreate all indexes of the specified table. If the table has a secondary "TOAST" table, that is reindexed as well.
SCHEMA
Recreate all indexes of the specified schema. If a table of this schema has a secondary "TOAST" table, that is reindexed as well. Indexes on shared system catalogs are also processed. You cannot run this form of REINDEX
inside a transaction block.
DATABASE
Recreate all indexes within the current database. Indexes on shared system catalogs are also processed. This form of REINDEX
cannot be run inside a transaction block.
SYSTEM
Recreate all indexes on system catalogs within the current database. Indexes on shared system catalogs are included. Indexes on user tables are not processed. This form of REINDEX
cannot be run inside a transaction block.
name
The name of the specific index, table, or database to be reindexed. Index and table names may be schema-qualified. Presently, REINDEX DATABASE
and REINDEX SYSTEM
can only reindex the current database, so their parameter must match the current database's name.
VERBOSE
Prints a progress report as each index is reindexed.
Notes
Cloudberry Database does not support concurrently recreating indexes (CONCURRENTLY
keyword is not supported).
REINDEX
causes locking of system catalog tables, which could affect currently running queries. To avoid disrupting ongoing business operations, schedule the REINDEX
operation during a period of low activity.
REINDEX
is similar to a drop and recreate of the index in that the index contents are rebuilt from scratch. However, the locking considerations are rather different. REINDEX
locks out writes but not reads of the index's parent table. It also takes an ACCESS EXCLUSIVE
lock on the specific index being processed, which will block reads that attempt to use that index. In contrast, DROP INDEX
momentarily takes an ACCESS EXCLUSIVE
lock on the parent table, blocking both writes and reads. The subsequent CREATE INDEX
locks out writes but not reads; since the index is not there, no read will attempt to use it, meaning that there will be no blocking but reads may be forced into expensive sequential scans.
Reindexing a single index or table requires being the owner of that index or table. Reindexing a schema or database requires being the owner of the schema or database. Note that it is therefore sometimes possible for non-superusers to rebuild indexes of tables owned by other users. However, as a special exception, when a non-superuser issues REINDEX DATABASE
, REINDEX SCHEMA
or REINDEX SYSTEM
, Cloudberry Database skips indexes on shared catalogs unless the user owns the catalog (which typically won't be the case). Of course, superusers can always reindex anything.
REINDEXdoes not update the
reltuplesand
relpagesstatistics for the index. To update those statistics, run
ANALYZE` on the table after reindexing.
Examples
Rebuild a single index:
REINDEX INDEX my_index;
Rebuild all the indexes on the table my_table
:
REINDEX TABLE my_table;
Rebuild all indexes in a particular database, without trusting the system indexes to be valid already:
$ export PGOPTIONS="-P"
$ psql broken_db
...
broken_db=> REINDEX DATABASE broken_db;
broken_db=> \q
Compatibility
There is no REINDEX
command in the SQL standard.
See also
CREATE INDEX, DROP INDEX, VACUUM, reindexdb