1REINDEX(7) PostgreSQL 9.2.24 Documentation REINDEX(7)
2
3
4
6 REINDEX - rebuild indexes
7
9 REINDEX { INDEX | TABLE | DATABASE | SYSTEM } name [ FORCE ]
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 23.2, “Routine Reindexing”, in the documentation for more
27 information.
28
29 · You have altered a storage parameter (such as fillfactor) for an
30 index, and wish to ensure that the change has taken full effect.
31
32 · An index build with the CONCURRENTLY option failed, leaving an
33 “invalid” index. Such indexes are useless but it can be convenient
34 to use REINDEX to rebuild them. Note that REINDEX will not perform
35 a concurrent build. To build the index without interfering with
36 production you should drop the index and reissue the CREATE INDEX
37 CONCURRENTLY command.
38
40 INDEX
41 Recreate the specified index.
42
43 TABLE
44 Recreate all indexes of the specified table. If the table has a
45 secondary “TOAST” table, that is reindexed as well.
46
47 DATABASE
48 Recreate all indexes within the current database. Indexes on shared
49 system catalogs are also processed. This form of REINDEX cannot be
50 executed inside a transaction block.
51
52 SYSTEM
53 Recreate all indexes on system catalogs within the current
54 database. Indexes on shared system catalogs are included. Indexes
55 on user tables are not processed. This form of REINDEX cannot be
56 executed inside a transaction block.
57
58 name
59 The name of the specific index, table, or database to be reindexed.
60 Index and table names can be schema-qualified. Presently, REINDEX
61 DATABASE and REINDEX SYSTEM can only reindex the current database,
62 so their parameter must match the current database's name.
63
64 FORCE
65 This is an obsolete option; it is ignored if specified.
66
68 If you suspect corruption of an index on a user table, you can simply
69 rebuild that index, or all indexes on the table, using REINDEX INDEX or
70 REINDEX TABLE.
71
72 Things are more difficult if you need to recover from corruption of an
73 index on a system table. In this case it's important for the system to
74 not have used any of the suspect indexes itself. (Indeed, in this sort
75 of scenario you might find that server processes are crashing
76 immediately at start-up, due to reliance on the corrupted indexes.) To
77 recover safely, the server must be started with the -P option, which
78 prevents it from using indexes for system catalog lookups.
79
80 One way to do this is to shut down the server and start a single-user
81 PostgreSQL server with the -P option included on its command line.
82 Then, REINDEX DATABASE, REINDEX SYSTEM, REINDEX TABLE, or REINDEX INDEX
83 can be issued, depending on how much you want to reconstruct. If in
84 doubt, use REINDEX SYSTEM to select reconstruction of all system
85 indexes in the database. Then quit the single-user server session and
86 restart the regular server. See the postgres(1) reference page for more
87 information about how to interact with the single-user server
88 interface.
89
90 Alternatively, a regular server session can be started with -P included
91 in its command line options. The method for doing this varies across
92 clients, but in all libpq-based clients, it is possible to set the
93 PGOPTIONS environment variable to -P before starting the client. Note
94 that while this method does not require locking out other clients, it
95 might still be wise to prevent other users from connecting to the
96 damaged database until repairs have been completed.
97
98 REINDEX is similar to a drop and recreate of the index in that the
99 index contents are rebuilt from scratch. However, the locking
100 considerations are rather different. REINDEX locks out writes but not
101 reads of the index's parent table. It also takes an exclusive lock on
102 the specific index being processed, which will block reads that attempt
103 to use that index. In contrast, DROP INDEX momentarily takes an
104 exclusive lock on the parent table, blocking both writes and reads. The
105 subsequent CREATE INDEX locks out writes but not reads; since the index
106 is not there, no read will attempt to use it, meaning that there will
107 be no blocking but reads might be forced into expensive sequential
108 scans.
109
110 Reindexing a single index or table requires being the owner of that
111 index or table. Reindexing a database requires being the owner of the
112 database (note that the owner can therefore rebuild indexes of tables
113 owned by other users). Of course, superusers can always reindex
114 anything.
115
116 Prior to PostgreSQL 8.1, REINDEX DATABASE processed only system
117 indexes, not all indexes as one would expect from the name. This has
118 been changed to reduce the surprise factor. The old behavior is
119 available as REINDEX SYSTEM.
120
121 Prior to PostgreSQL 7.4, REINDEX TABLE did not automatically process
122 TOAST tables, and so those had to be reindexed by separate commands.
123 This is still possible, but redundant.
124
126 Rebuild a single index:
127
128 REINDEX INDEX my_index;
129
130 Rebuild all the indexes on the table my_table:
131
132 REINDEX TABLE my_table;
133
134 Rebuild all indexes in a particular database, without trusting the
135 system indexes to be valid already:
136
137 $ export PGOPTIONS="-P"
138 $ psql broken_db
139 ...
140 broken_db=> REINDEX DATABASE broken_db;
141 broken_db=> \q
142
144 There is no REINDEX command in the SQL standard.
145
146
147
148PostgreSQL 9.2.24 2017-11-06 REINDEX(7)