1REINDEX(7) PostgreSQL 11.3 Documentation REINDEX(7)
2
3
4
6 REINDEX - rebuild indexes
7
9 REINDEX [ ( VERBOSE ) ] { INDEX | TABLE | SCHEMA | DATABASE | SYSTEM } name
10
12 REINDEX rebuilds an index using the data stored in the index's table,
13 replacing the old copy of the index. There are several scenarios in
14 which to use REINDEX:
15
16 · An index has become corrupted, and no longer contains valid data.
17 Although in theory this should never happen, in practice indexes
18 can become corrupted due to software bugs or hardware failures.
19 REINDEX provides a recovery method.
20
21 · An index has become “bloated”, that is it contains many empty or
22 nearly-empty pages. This can occur with B-tree indexes in
23 PostgreSQL under certain uncommon access patterns. REINDEX
24 provides a way to reduce the space consumption of the index by
25 writing a new version of the index without the dead pages. See
26 Section 24.2 for more information.
27
28 · You have altered a storage parameter (such as fillfactor) for an
29 index, and wish to ensure that the change has taken full effect.
30
31 · An index build with the CONCURRENTLY option failed, leaving an
32 “invalid” index. Such indexes are useless but it can be convenient
33 to use REINDEX to rebuild them. Note that REINDEX will not perform
34 a concurrent build. To build the index without interfering with
35 production you should drop the index and reissue the CREATE INDEX
36 CONCURRENTLY command.
37
39 INDEX
40 Recreate the specified index.
41
42 TABLE
43 Recreate all indexes of the specified table. If the table has a
44 secondary “TOAST” table, that is reindexed as well.
45
46 SCHEMA
47 Recreate all indexes of the specified schema. If a table of this
48 schema has a secondary “TOAST” table, that is reindexed as well.
49 Indexes on shared system catalogs are also processed. This form of
50 REINDEX cannot be executed inside a transaction block.
51
52 DATABASE
53 Recreate all indexes within the current database. Indexes on shared
54 system catalogs are also processed. This form of REINDEX cannot be
55 executed inside a transaction block.
56
57 SYSTEM
58 Recreate all indexes on system catalogs within the current
59 database. Indexes on shared system catalogs are included. Indexes
60 on user tables are not processed. This form of REINDEX cannot be
61 executed inside a transaction block.
62
63 name
64 The name of the specific index, table, or database to be reindexed.
65 Index and table names can be schema-qualified. Presently, REINDEX
66 DATABASE and REINDEX SYSTEM can only reindex the current database,
67 so their parameter must match the current database's name.
68
69 VERBOSE
70 Prints a progress report as each index is reindexed.
71
73 If you suspect corruption of an index on a user table, you can simply
74 rebuild that index, or all indexes on the table, using REINDEX INDEX or
75 REINDEX TABLE.
76
77 Things are more difficult if you need to recover from corruption of an
78 index on a system table. In this case it's important for the system to
79 not have used any of the suspect indexes itself. (Indeed, in this sort
80 of scenario you might find that server processes are crashing
81 immediately at start-up, due to reliance on the corrupted indexes.) To
82 recover safely, the server must be started with the -P option, which
83 prevents it from using indexes for system catalog lookups.
84
85 One way to do this is to shut down the server and start a single-user
86 PostgreSQL server with the -P option included on its command line.
87 Then, REINDEX DATABASE, REINDEX SYSTEM, REINDEX TABLE, or REINDEX INDEX
88 can be issued, depending on how much you want to reconstruct. If in
89 doubt, use REINDEX SYSTEM to select reconstruction of all system
90 indexes in the database. Then quit the single-user server session and
91 restart the regular server. See the postgres(1) reference page for more
92 information about how to interact with the single-user server
93 interface.
94
95 Alternatively, a regular server session can be started with -P included
96 in its command line options. The method for doing this varies across
97 clients, but in all libpq-based clients, it is possible to set the
98 PGOPTIONS environment variable to -P before starting the client. Note
99 that while this method does not require locking out other clients, it
100 might still be wise to prevent other users from connecting to the
101 damaged database until repairs have been completed.
102
103 REINDEX is similar to a drop and recreate of the index in that the
104 index contents are rebuilt from scratch. However, the locking
105 considerations are rather different. REINDEX locks out writes but not
106 reads of the index's parent table. It also takes an exclusive lock on
107 the specific index being processed, which will block reads that attempt
108 to use that index. In contrast, DROP INDEX momentarily takes an
109 exclusive lock on the parent table, blocking both writes and reads. The
110 subsequent CREATE INDEX locks out writes but not reads; since the index
111 is not there, no read will attempt to use it, meaning that there will
112 be no blocking but reads might be forced into expensive sequential
113 scans.
114
115 Reindexing a single index or table requires being the owner of that
116 index or table. Reindexing a schema or database requires being the
117 owner of that schema or database. Note that is therefore sometimes
118 possible for non-superusers to rebuild indexes of tables owned by other
119 users. However, as a special exception, when REINDEX DATABASE, REINDEX
120 SCHEMA or REINDEX SYSTEM is issued by a non-superuser, indexes on
121 shared catalogs will be skipped unless the user owns the catalog (which
122 typically won't be the case). Of course, superusers can always reindex
123 anything.
124
125 Reindexing partitioned tables or partitioned indexes is not supported.
126 Each individual partition can be reindexed separately instead.
127
129 Rebuild a single index:
130
131 REINDEX INDEX my_index;
132
133 Rebuild all the indexes on the table my_table:
134
135 REINDEX TABLE my_table;
136
137 Rebuild all indexes in a particular database, without trusting the
138 system indexes to be valid already:
139
140 $ export PGOPTIONS="-P"
141 $ psql broken_db
142 ...
143 broken_db=> REINDEX DATABASE broken_db;
144 broken_db=> \q
145
147 There is no REINDEX command in the SQL standard.
148
149
150
151PostgreSQL 11.3 2019 REINDEX(7)