3 .\" Author: The PostgreSQL Global Development Group
4 .\" Generator: DocBook XSL Stylesheets vsnapshot <http://docbook.sf.net/>
6 .\" Manual: PostgreSQL 18.0 Documentation
7 .\" Source: PostgreSQL 18.0
10 .TH "REINDEX" "7" "2025" "PostgreSQL 18.0" "PostgreSQL 18.0 Documentation"
11 .\" -----------------------------------------------------------------
12 .\" * Define some portability stuff
13 .\" -----------------------------------------------------------------
14 .\" ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
15 .\" http://bugs.debian.org/507673
16 .\" http://lists.gnu.org/archive/html/groff/2009-02/msg00013.html
17 .\" ~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~~
20 .\" -----------------------------------------------------------------
21 .\" * set default formatting
22 .\" -----------------------------------------------------------------
23 .\" disable hyphenation
25 .\" disable justification (adjust text to left margin only)
27 .\" -----------------------------------------------------------------
28 .\" * MAIN CONTENT STARTS HERE *
29 .\" -----------------------------------------------------------------
31 REINDEX \- rebuild indexes
35 REINDEX [ ( \fIoption\fR [, \&.\&.\&.] ) ] { INDEX | TABLE | SCHEMA } [ CONCURRENTLY ] \fIname\fR
36 REINDEX [ ( \fIoption\fR [, \&.\&.\&.] ) ] { DATABASE | SYSTEM } [ CONCURRENTLY ] [ \fIname\fR ]
38 where \fIoption\fR can be one of:
40 CONCURRENTLY [ \fIboolean\fR ]
41 TABLESPACE \fInew_tablespace\fR
42 VERBOSE [ \fIboolean\fR ]
47 rebuilds an index using the data stored in the index\*(Aqs table, replacing the old copy of the index\&. There are several scenarios in which to use
58 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\&.
60 provides a recovery method\&.
72 \(lqbloated\(rq, that is it contains many empty or nearly\-empty pages\&. This can occur with B\-tree indexes in
74 under certain uncommon access patterns\&.
76 provides a way to reduce the space consumption of the index by writing a new version of the index without the dead pages\&. See
78 for more information\&.
89 You have altered a storage parameter (such as fillfactor) for an index, and wish to ensure that the change has taken full effect\&.
100 If an index build fails with the
102 option, this index is left as
103 \(lqinvalid\(rq\&. Such indexes are useless but it can be convenient to use
105 to rebuild them\&. Note that only
107 is able to perform a concurrent build on an invalid index\&.
113 Recreate the specified index\&. This form of
115 cannot be executed inside a transaction block when used with a partitioned index\&.
120 Recreate all indexes of the specified table\&. If the table has a secondary
122 table, that is reindexed as well\&. This form of
124 cannot be executed inside a transaction block when used with a partitioned table\&.
129 Recreate all indexes of the specified schema\&. If a table of this schema has a secondary
131 table, that is reindexed as well\&. Indexes on shared system catalogs are also processed\&. This form of
133 cannot be executed inside a transaction block\&.
138 Recreate all indexes within the current database, except system catalogs\&. Indexes on system catalogs are not processed\&. This form of
140 cannot be executed inside a transaction block\&.
145 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
147 cannot be executed inside a transaction block\&.
152 The name of the specific index, table, or database to be reindexed\&. Index and table names can be schema\-qualified\&. Presently,
153 \fBREINDEX DATABASE\fR
156 can only reindex the current database\&. Their parameter is optional, and it must match the current database\*(Aqs name\&.
161 When this option is used,
163 will rebuild the index without taking any locks that prevent concurrent inserts, updates, or deletes on the table; whereas a standard index rebuild locks out writes (but not reads) on the table until it\*(Aqs done\&. There are several caveats to be aware of when using this option \(em see
164 Rebuilding Indexes Concurrently
167 For temporary tables,
169 is always non\-concurrent, as no other session can access them, and non\-concurrent reindex is cheaper\&.
174 Specifies that indexes will be rebuilt on a new tablespace\&.
179 Prints a progress report as each index is reindexed at
186 Specifies whether the selected option should be turned on or off\&. You can write
190 to enable the option, and
196 value can also be omitted, in which case
203 The tablespace where indexes will be rebuilt\&.
207 If you suspect corruption of an index on a user table, you can simply rebuild that index, or all indexes on the table, using
210 \fBREINDEX TABLE\fR\&.
212 Things are more difficult if you need to recover from corruption of an index on a system table\&. In this case it\*(Aqs important for the system to not have used any of the suspect indexes itself\&. (Indeed, in this sort of scenario you might find that server processes are crashing immediately at start\-up, due to reliance on the corrupted indexes\&.) To recover safely, the server must be started with the
214 option, which prevents it from using indexes for system catalog lookups\&.
216 One way to do this is to shut down the server and start a single\-user
220 option included on its command line\&. Then,
221 \fBREINDEX DATABASE\fR,
222 \fBREINDEX SYSTEM\fR,
223 \fBREINDEX TABLE\fR, or
225 can be issued, depending on how much you want to reconstruct\&. If in doubt, use
227 to select reconstruction of all system indexes in the database\&. Then quit the single\-user server session and restart the regular server\&. See the
229 reference page for more information about how to interact with the single\-user server interface\&.
231 Alternatively, a regular server session can be started with
233 included in its command line options\&. The method for doing this varies across clients, but in all
234 libpq\-based clients, it is possible to set the
236 environment variable to
238 before starting the client\&. Note that while this method does not require locking out other clients, it might still be wise to prevent other users from connecting to the damaged database until repairs have been completed\&.
241 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\&.
243 locks out writes but not reads of the index\*(Aqs parent table\&. It also takes an
245 lock on the specific index being processed, which will block reads that attempt to use that index\&. In particular, the query planner tries to take an
247 lock on every index of the table, regardless of the query, and so
249 blocks virtually any queries except for some prepared queries whose plan has been cached and which don\*(Aqt use this very index\&. In contrast,
253 lock on the parent table, blocking both writes and reads\&. The subsequent
255 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 might be forced into expensive sequential scans\&.
261 is temporarily changed to
262 pg_catalog, pg_temp\&.
264 Reindexing a single index or table requires having the
266 privilege on the table\&. Note that while
268 on a partitioned index or table requires having the
270 privilege on the partitioned table, such commands skip the privilege checks when processing the individual partitions\&. Reindexing a schema or database requires being the owner of that schema or database or having privileges of the
272 role\&. Note specifically that it\*(Aqs thus possible for non\-superusers to rebuild indexes of tables owned by other users\&. However, as a special exception,
273 \fBREINDEX DATABASE\fR,
274 \fBREINDEX SCHEMA\fR, and
276 will skip indexes on shared catalogs unless the user has the
278 privilege on the catalog\&.
280 Reindexing partitioned indexes or partitioned tables is supported with
283 \fBREINDEX TABLE\fR, respectively\&. Each partition of the specified partitioned relation is reindexed in a separate transaction\&. Those commands cannot be used inside a transaction block when working on a partitioned table or index\&.
289 on a partitioned index or table, only the tablespace references of the leaf partitions are updated\&. As partitioned indexes are not updated, it is recommended to separately use
290 \fBALTER TABLE ONLY\fR
291 on them so as any new partitions attached inherit the new tablespace\&. On failure, it may not have moved all the indexes to the new tablespace\&. Re\-running the command will rebuild all the leaf partitions and move previously\-unprocessed indexes to the new tablespace\&.
299 TABLESPACE, system relations are skipped and a single
301 will be generated\&. Indexes on TOAST tables are rebuilt, but not moved to the new tablespace\&.
302 .SS "Rebuilding Indexes Concurrently"
304 Rebuilding an index can interfere with regular operation of a database\&. Normally
306 locks the table whose index is rebuilt against writes and performs the entire index build with a single scan of the table\&. Other transactions can still read the table, but if they try to insert, update, or delete rows in the table they will block until the index rebuild is finished\&. This could have a severe effect if the system is a live production database\&. Very large tables can take many hours to be indexed, and even for smaller tables, an index rebuild can lock out writers for periods that are unacceptably long for a production system\&.
309 supports rebuilding indexes with minimum locking of writes\&. This method is invoked by specifying the
312 \fBREINDEX\fR\&. When this option is used,
314 must perform two scans of the table for each index that needs to be rebuilt and wait for termination of all existing transactions that could potentially use the index\&. This method requires more total work than a standard index rebuild and takes significantly longer to complete as it needs to wait for unfinished transactions that might modify the index\&. However, since it allows normal operations to continue while the index is being rebuilt, this method is useful for rebuilding indexes in a production environment\&. Of course, the extra CPU, memory and I/O load imposed by the index rebuild may slow down other operations\&.
316 The following steps occur in a concurrent reindex\&. Each step is run in a separate transaction\&. If there are multiple indexes to be rebuilt, then each step loops through all the indexes before moving to the next step\&.
326 A new transient index definition is added to the catalog
327 pg_index\&. This definition will be used to replace the old index\&. A
328 SHARE UPDATE EXCLUSIVE
329 lock at session level is taken on the indexes being reindexed as well as their associated tables to prevent any schema modification while processing\&.
340 A first pass to build the index is done for each new index\&. Once the index is built, its flag
341 pg_index\&.indisready
344 to make it ready for inserts, making it visible to other sessions once the transaction that performed the build is finished\&. This step is done in a separate transaction for each index\&.
355 Then a second pass is performed to add tuples that were added while the first pass was running\&. This step is also done in a separate transaction for each index\&.
366 All the constraints that refer to the index are changed to refer to the new index definition, and the names of the indexes are changed\&. At this point,
367 pg_index\&.indisvalid
370 for the new index and to
372 for the old, and a cache invalidation is done causing all sessions that referenced the old index to be invalidated\&.
384 pg_index\&.indisready
387 to prevent any new tuple insertions, after waiting for running queries that might reference the old index to complete\&.
398 The old indexes are dropped\&. The
399 SHARE UPDATE EXCLUSIVE
400 session locks for the indexes and the table are released\&.
403 If a problem arises while rebuilding the indexes, such as a uniqueness violation in a unique index, the
405 command will fail but leave behind an
407 new index in addition to the pre\-existing one\&. This index will be ignored for querying purposes because it might be incomplete; however it will still consume update overhead\&. The
410 command will report such an index as
419 Column | Type | Modifiers
420 \-\-\-\-\-\-\-\-+\-\-\-\-\-\-\-\-\-+\-\-\-\-\-\-\-\-\-\-\-
424 "idx_ccnew" btree (col) INVALID
433 _ccnew, then it corresponds to the transient index created during the concurrent operation, and the recommended recovery method is to drop it using
434 DROP INDEX, then attempt
435 \fBREINDEX CONCURRENTLY\fR
436 again\&. If the invalid index is instead suffixed
437 _ccold, it corresponds to the original index which could not be dropped; the recommended recovery method is to just drop said index, since the rebuild proper has been successful\&. A nonzero number may be appended to the suffix of the invalid index names to keep them unique, like
441 Regular index builds permit other regular index builds on the same table to occur simultaneously, but only one concurrent index build can occur on a table at a time\&. In both cases, no other types of schema modification on the table are allowed meanwhile\&. Another difference is that a regular
445 command can be performed within a transaction block, but
446 \fBREINDEX CONCURRENTLY\fR
449 Like any long\-running transaction,
451 on a table can affect which tuples can be removed by concurrent
453 on any other table\&.
458 since system catalogs cannot be reindexed concurrently\&.
460 Furthermore, indexes for exclusion constraints cannot be reindexed concurrently\&. If such an index is named directly in this command, an error is raised\&. If a table or database with exclusion constraint indexes is reindexed concurrently, those indexes will be skipped\&. (It is possible to reindex such indexes without the
466 will report its progress in the
467 pg_stat_progress_create_index
473 Rebuild a single index:
479 REINDEX INDEX my_index;
485 Rebuild all the indexes on the table
492 REINDEX TABLE my_table;
498 Rebuild all indexes in a particular database, without trusting the system indexes to be valid already:
504 $ \fBexport PGOPTIONS="\-P"\fR
505 $ \fBpsql broken_db\fR
507 broken_db=> REINDEX DATABASE broken_db;
514 Rebuild indexes for a table, without blocking read and write operations on involved relations while reindexing is in progress:
520 REINDEX TABLE CONCURRENTLY my_broken_table;
529 command in the SQL standard\&.
531 CREATE INDEX (\fBCREATE_INDEX\fR(7)), DROP INDEX (\fBDROP_INDEX\fR(7)), \fBreindexdb\fR(1), Section\ \&27.4.4