1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
|
<!--
$PostgreSQL: pgsql/doc/src/sgml/ref/reindex.sgml,v 1.23 2003/11/29 19:51:39 pgsql Exp $
PostgreSQL documentation
-->
<refentry id="SQL-REINDEX">
<refmeta>
<refentrytitle id="SQL-REINDEX-TITLE">REINDEX</refentrytitle>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>REINDEX</refname>
<refpurpose>rebuild indexes</refpurpose>
</refnamediv>
<indexterm zone="sql-reindex">
<primary>REINDEX</primary>
</indexterm>
<refsynopsisdiv>
<synopsis>
REINDEX { DATABASE | TABLE | INDEX } <replaceable class="PARAMETER">name</replaceable> [ FORCE ]
</synopsis>
</refsynopsisdiv>
<refsect1>
<title>Description</title>
<para>
<command>REINDEX</command> rebuilds an index based on the data
stored in the table, replacing the old copy of the index. There are
two main reasons to use <command>REINDEX</command>:
<itemizedlist>
<listitem>
<para>
An index has become corrupted, and no longer contains valid
data. Although in theory this should never happen, in
practice indexes may become corrupted due to software bugs or
hardware failures. <command>REINDEX</command> provides a
recovery method.
</para>
</listitem>
<listitem>
<para>
The index in question contains a lot of dead index pages that
are not being reclaimed. This can occur with B-tree indexes in
<productname>PostgreSQL</productname> under certain access
patterns. <command>REINDEX</command> provides a way to reduce
the space consumption of the index by writing a new version of
the index without the dead pages. See <xref
linkend="routine-reindex"> for more information.
</para>
</listitem>
</itemizedlist>
</para>
</refsect1>
<refsect1>
<title>Parameters</title>
<variablelist>
<varlistentry>
<term><literal>DATABASE</literal></term>
<listitem>
<para>
Recreate all system indexes of a specified database. Indexes on
user tables are not processed. Also, indexes on shared system
catalogs are skipped except in stand-alone mode (see below).
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>TABLE</literal></term>
<listitem>
<para>
Recreate all indexes of a specified table. If the table has a
secondary <quote>TOAST</> table, that is reindexed as well.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>INDEX</literal></term>
<listitem>
<para>
Recreate a specified index.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">name</replaceable></term>
<listitem>
<para>
The name of the specific database, table, or index to be
reindexed. Table and index names may be schema-qualified.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>FORCE</literal></term>
<listitem>
<para>
This is an obsolete option; it is ignored if specified.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Notes</title>
<para>
If you suspect corruption of an index on a user table, you can
simply rebuild that index, or all indexes on the table, using
<command>REINDEX INDEX</command> or <command>REINDEX
TABLE</command>. Another approach to dealing with a corrupted
user-table index is just to drop and recreate it. This may in fact
be preferable if you would like to maintain some semblance of
normal operation on the table meanwhile. <command>REINDEX</>
acquires exclusive lock on the table, while <command>CREATE
INDEX</> only locks out writes not reads of the table.
</para>
<para>
Things are more difficult if you need to recover from corruption of
an index on a system table. In this case it's important for the
system to not have used any of the suspect indexes itself.
(Indeed, in this sort of scenario you may 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 <option>-P</option> option, which prevents it from using
indexes for system catalog lookups.
</para>
<para>
One way to do this is to shut down the postmaster and start a stand-alone
<productname>PostgreSQL</productname> server
with the <option>-P</option> option included on its command line.
Then, <command>REINDEX DATABASE</>,
<command>REINDEX TABLE</>, or <command>REINDEX INDEX</> can be
issued, depending on how much you want to reconstruct. If in
doubt, use <command>REINDEX DATABASE</> to select
reconstruction of all system indexes in the database. Then quit
the standalone server session and restart the regular server.
See the <xref linkend="app-postgres"> reference page for more
information about how to interact with the stand-alone server
interface.
</para>
<para>
Alternatively, a regular server session can be started with
<option>-P</option> included in its command line options.
The method for doing this varies across clients, but in all
<application>libpq</>-based clients, it is possible to set
the <envar>PGOPTIONS</envar> environment variable to <literal>-P</>
before starting the client. Note that while this method does not
require locking out other clients, it may still be wise to prevent
other users from connecting to the damaged database until repairs
have been completed.
</para>
<para>
If corruption is suspected in the indexes of any of the shared
system catalogs (<structname>pg_database</structname>,
<structname>pg_group</structname>, or
<structname>pg_shadow</structname>), then a standalone server
must be used to repair it. <command>REINDEX</> will not process
shared catalogs in multiuser mode.
</para>
<para>
For all indexes except the shared system catalogs, <command>REINDEX</>
is crash-safe and transaction-safe. <command>REINDEX</> is not
crash-safe for shared indexes, which is why this case is disallowed
during normal operation. If a failure occurs while reindexing one
of these catalogs in standalone mode, it will not be possible to
restart the regular server until the problem is rectified. (The
typical symptom of a partially rebuilt shared index is <quote>index is not
a btree</> errors.)
</para>
<para>
Prior to <productname>PostgreSQL</productname> 7.4, <command>REINDEX
TABLE</> did not automatically process TOAST tables, and so those had
to be reindexed by separate commands. This is still possible, but
redundant.
</para>
</refsect1>
<refsect1>
<title>Examples</title>
<para>
Recreate the indexes on the table <literal>my_table</literal>:
<programlisting>
REINDEX TABLE my_table;
</programlisting>
</para>
<para>
Rebuild a single index:
<programlisting>
REINDEX INDEX my_index;
</programlisting>
</para>
<para>
Rebuild all system indexes in a particular database, without trusting them
to be valid already:
<programlisting>
$ <userinput>export PGOPTIONS="-P"</userinput>
$ <userinput>psql broken_db</userinput>
...
broken_db=> REINDEX DATABASE broken_db;
broken_db=> \q
</programlisting>
</para>
</refsect1>
<refsect1>
<title>Compatibility</title>
<para>
There is no <command>REINDEX</command> command in the SQL standard.
</para>
</refsect1>
</refentry>
<!-- Keep this comment at the end of the file
Local variables:
mode: sgml
sgml-omittag:t
sgml-shorttag:t
sgml-minimize-attributes:nil
sgml-always-quote-attributes:t
sgml-indent-step:1
sgml-indent-data:t
sgml-parent-document:nil
sgml-default-dtd-file:"../reference.ced"
sgml-exposed-tags:nil
sgml-local-catalogs:"/usr/lib/sgml/catalog"
sgml-local-ecat-files:nil
End:
-->
|