1REINDEX(7) SQL Commands REINDEX(7)
2
3
4
6 REINDEX - rebuild indexes
7
8
10 REINDEX { INDEX | TABLE | DATABASE | SYSTEM } name [ FORCE ]
11
12
14 REINDEX rebuilds an index using the data stored in the index's table,
15 replacing the old copy of the index. There are several scenarios in
16 which to use REINDEX:
17
18 · An index has become corrupted, and no longer contains valid data.
19 Although in theory this should never happen, in practice indexes can
20 become corrupted due to software bugs or hardware failures. REINDEX
21 provides a recovery method.
22
23 · An index has become ``bloated'', that it is contains many empty or
24 nearly-empty pages. This can occur with B-tree indexes in PostgreSQL
25 under certain uncommon access patterns. REINDEX provides a way to
26 reduce the space consumption of the index by writing a new version of
27 the index without the dead pages. See in the documentation for more
28 information.
29
30 · You have altered a storage parameter (such as fillfactor) for an
31 index, and wish to ensure that the change has taken full effect.
32
33 · An index build with the CONCURRENTLY option failed, leaving an
34 ``invalid'' index. Such indexes are useless but it can be convenient
35 to use REINDEX to rebuild them. Note that REINDEX will not perform a
36 concurrent build. To build the index without interfering with produc‐
37 tion you should drop the index and reissue the CREATE INDEX CONCUR‐
38 RENTLY command.
39
41 INDEX Recreate the specified index.
42
43 TABLE Recreate all indexes of the specified table. If the table has a
44 secondary ``TOAST'' table, that is reindexed as well.
45
46 DATABASE
47 Recreate all indexes within the current database. Indexes on
48 shared system catalogs are skipped except in stand-alone mode
49 (see below). This form of REINDEX cannot be executed inside a
50 transaction block.
51
52 SYSTEM Recreate all indexes on system catalogs within the current data‐
53 base. Indexes on user tables are not processed. Also, indexes
54 on shared system catalogs are skipped except in stand-alone mode
55 (see below). This form of REINDEX cannot be executed inside a
56 transaction block.
57
58 name The name of the specific index, table, or database to be rein‐
59 dexed. Index and table names can be schema-qualified.
60 Presently, REINDEX DATABASE and REINDEX SYSTEM can only reindex
61 the current database, so their parameter must match the current
62 database's name.
63
64 FORCE This is an obsolete option; it is ignored if specified.
65
67 If you suspect corruption of an index on a user table, you can simply
68 rebuild that index, or all indexes on the table, using REINDEX INDEX or
69 REINDEX TABLE.
70
71 Things are more difficult if you need to recover from corruption of an
72 index on a system table. In this case it's important for the system to
73 not have used any of the suspect indexes itself. (Indeed, in this sort
74 of scenario you might find that server processes are crashing immedi‐
75 ately at start-up, due to reliance on the corrupted indexes.) To
76 recover safely, the server must be started with the -P option, which
77 prevents it from using indexes for system catalog lookups.
78
79 One way to do this is to shut down the server and start a single-user
80 PostgreSQL server with the -P option included on its command line.
81 Then, REINDEX DATABASE, REINDEX SYSTEM, REINDEX TABLE, or REINDEX INDEX
82 can be issued, depending on how much you want to reconstruct. If in
83 doubt, use REINDEX SYSTEM to select reconstruction of all system
84 indexes in the database. Then quit the single-user server session and
85 restart the regular server. See the postgres(1) reference page for
86 more information about how to interact with the single-user server
87 interface.
88
89 Alternatively, a regular server session can be started with -P included
90 in its command line options. The method for doing this varies across
91 clients, but in all libpq-based clients, it is possible to set the
92 PGOPTIONS environment variable to -P before starting the client. Note
93 that while this method does not require locking out other clients, it
94 might still be wise to prevent other users from connecting to the dam‐
95 aged database until repairs have been completed.
96
97 If corruption is suspected in the indexes of any of the shared system
98 catalogs (which are pg_authid, pg_auth_members, pg_database, pg_pltem‐
99 plate, pg_shdepend, pg_shdescription, and pg_tablespace), then a stand‐
100 alone server must be used to repair it. REINDEX will not process shared
101 catalogs in multiuser mode.
102
103 For all indexes except the shared system catalogs, REINDEX is crash-
104 safe and transaction-safe. REINDEX is not crash-safe for shared
105 indexes, which is why this case is disallowed during normal operation.
106 If a failure occurs while reindexing one of these catalogs in stand‐
107 alone mode, it will not be possible to restart the regular server until
108 the problem is rectified. (The typical symptom of a partially rebuilt
109 shared index is ``index is not a btree'' errors.)
110
111 REINDEX is similar to a drop and recreate of the index in that the
112 index contents are rebuilt from scratch. However, the locking consider‐
113 ations are rather different. REINDEX locks out writes but not reads of
114 the index's parent table. It also takes an exclusive lock on the spe‐
115 cific index being processed, which will block reads that attempt to use
116 that index. In contrast, DROP INDEX momentarily takes exclusive lock on
117 the parent table, blocking both writes and reads. The subsequent CREATE
118 INDEX locks out writes but not reads; since the index is not there, no
119 read will attempt to use it, meaning that there will be no blocking but
120 reads might be forced into expensive sequential scans.
121
122 Reindexing a single index or table requires being the owner of that
123 index or table. Reindexing a database requires being the owner of the
124 database (note that the owner can therefore rebuild indexes of tables
125 owned by other users). Of course, superusers can always reindex any‐
126 thing.
127
128 Prior to PostgreSQL 8.1, REINDEX DATABASE processed only system
129 indexes, not all indexes as one would expect from the name. This has
130 been changed to reduce the surprise factor. The old behavior is avail‐
131 able as REINDEX SYSTEM.
132
133 Prior to PostgreSQL 7.4, REINDEX TABLE did not automatically process
134 TOAST tables, and so those had to be reindexed by separate commands.
135 This is still possible, but redundant.
136
138 Rebuild a single index:
139
140 REINDEX INDEX my_index;
141
142
143 Rebuild all the indexes on the table my_table:
144
145 REINDEX TABLE my_table;
146
147
148 Rebuild all indexes in a particular database, without trusting the sys‐
149 tem indexes to be valid already:
150
151 $ export PGOPTIONS="-P"
152 $ psql broken_db
153 broken_db=> REINDEX DATABASE broken_db;
154 broken_db=> \q
155
156
158 There is no REINDEX command in the SQL standard.
159
160
161
162SQL - Language Statements 2014-02-17 REINDEX(7)