summaryrefslogtreecommitdiff
path: root/doc/src/sgml/ref/reindex.sgml
blob: 54422c3442cc612bb9f5eee2ccd3624285321956 (plain)
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
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
<!--
doc/src/sgml/ref/reindex.sgml
PostgreSQL documentation
-->

<refentry id="SQL-REINDEX">
 <indexterm zone="sql-reindex">
  <primary>REINDEX</primary>
 </indexterm>

 <refmeta>
  <refentrytitle>REINDEX</refentrytitle>
  <manvolnum>7</manvolnum>
  <refmiscinfo>SQL - Language Statements</refmiscinfo>
 </refmeta>

 <refnamediv>
  <refname>REINDEX</refname>
  <refpurpose>rebuild indexes</refpurpose>
 </refnamediv>

 <refsynopsisdiv>
<synopsis>
REINDEX { INDEX | TABLE | DATABASE | SYSTEM } <replaceable class="PARAMETER">name</replaceable> [ FORCE ]
</synopsis>
 </refsynopsisdiv>

 <refsect1>
  <title>Description</title>

  <para>
   <command>REINDEX</command> rebuilds an index using the data
   stored in the index's table, replacing the old copy of the index. There are
   several scenarios in which 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 can become corrupted due to software bugs or
      hardware failures.  <command>REINDEX</command> provides a
      recovery method.
     </para>
    </listitem>

    <listitem>
     <para>
      An index has become <quote>bloated</>, that it is contains many
      empty or nearly-empty pages.  This can occur with B-tree indexes in
      <productname>PostgreSQL</productname> under certain uncommon 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>

    <listitem>
     <para>
      You have altered a storage parameter (such as fillfactor)
      for an index, and wish to ensure that the change has taken full effect.
     </para>
    </listitem>

    <listitem>
     <para>
      An index build with the <literal>CONCURRENTLY</> option failed, leaving
      an <quote>invalid</> index. Such indexes are useless but it can be
      convenient to use <command>REINDEX</> to rebuild them. Note that
      <command>REINDEX</> will not perform a concurrent build. To build the
      index without interfering with production you should drop the index and
      reissue the <command>CREATE INDEX CONCURRENTLY</> command.
     </para>
    </listitem>

   </itemizedlist></para>
 </refsect1>

 <refsect1>
  <title>Parameters</title>

  <variablelist>
   <varlistentry>
    <term><literal>INDEX</literal></term>
    <listitem>
     <para>
      Recreate the specified index.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>TABLE</literal></term>
    <listitem>
     <para>
      Recreate all indexes of the specified table.  If the table has a
      secondary <quote>TOAST</> table, that is reindexed as well.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>DATABASE</literal></term>
    <listitem>
     <para>
      Recreate all indexes within the current database.
      Indexes on shared system catalogs are also processed.
      This form of <command>REINDEX</command> cannot be executed inside a
      transaction block.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><literal>SYSTEM</literal></term>
    <listitem>
     <para>
      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 <command>REINDEX</command> cannot be executed inside a
      transaction block.
     </para>
    </listitem>
   </varlistentry>

   <varlistentry>
    <term><replaceable class="PARAMETER">name</replaceable></term>
    <listitem>
     <para>
      The name of the specific index, table, or database to be
      reindexed.  Index and table names can be schema-qualified.
      Presently, <command>REINDEX DATABASE</> and <command>REINDEX SYSTEM</>
      can only reindex the current database, so their parameter must match
      the current database's name.
     </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>.
  </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 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 <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 server and start a single-user
   <productname>PostgreSQL</productname> server
   with the <option>-P</option> option included on its command line.
   Then, <command>REINDEX DATABASE</>, <command>REINDEX SYSTEM</>,
   <command>REINDEX TABLE</>, or <command>REINDEX INDEX</> can be
   issued, depending on how much you want to reconstruct.  If in
   doubt, use <command>REINDEX SYSTEM</> to select
   reconstruction of all system indexes in the database.  Then quit
   the single-user server session and restart the regular server.
   See the <xref linkend="app-postgres"> reference page for more
   information about how to interact with the single-user 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 might still be wise to prevent
   other users from connecting to the damaged database until repairs
   have been completed.
  </para>

  <para>
   <command>REINDEX</command> 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.  <command>REINDEX</> locks out writes
   but not reads of the index's parent table.  It also takes an exclusive lock
   on the specific index being processed, which will block reads that attempt
   to use that index.  In contrast, <command>DROP INDEX</> momentarily takes
   exclusive lock on the parent table, blocking both writes and reads.  The
   subsequent <command>CREATE INDEX</> 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.
  </para>

  <para>
   Reindexing a single index or table requires being the owner of that
   index or table.  Reindexing a database requires being the owner of
   the database (note that the owner can therefore rebuild indexes of
   tables owned by other users).  Of course, superusers can always
   reindex anything.
  </para>

  <para>
   Prior to <productname>PostgreSQL</productname> 8.1, <command>REINDEX
   DATABASE</> processed only system indexes, not all indexes as one would
   expect from the name.  This has been changed to reduce the surprise
   factor.  The old behavior is available as <command>REINDEX SYSTEM</>.
  </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>
   Rebuild a single index:

<programlisting>
REINDEX INDEX my_index;
</programlisting>
  </para>

  <para>
   Rebuild all the indexes on the table <literal>my_table</literal>:

<programlisting>
REINDEX TABLE my_table;
</programlisting>
  </para>

  <para>
   Rebuild all indexes in a particular database, without trusting the
   system indexes to be valid already:

<programlisting>
$ <userinput>export PGOPTIONS="-P"</userinput>
$ <userinput>psql broken_db</userinput>
...
broken_db=&gt; REINDEX DATABASE broken_db;
broken_db=&gt; \q
</programlisting></para>
 </refsect1>

 <refsect1>
  <title>Compatibility</title>

  <para>
   There is no <command>REINDEX</command> command in the SQL standard.
  </para>
 </refsect1>
</refentry>