postgresql/doc/src/sgml/ref/reindex.sgml
2003-04-26 23:56:51 +00:00

219 lines
6.1 KiB
Plaintext

<!--
$Header: /cvsroot/pgsql/doc/src/sgml/ref/reindex.sgml,v 1.17 2003/04/26 23:56:51 petere 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>
<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 PostgreSQL
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>
<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 shut
down and a stand-alone <productname>PostgreSQL</productname> server
must be started instead with the command-line options
<option>-O</option> and <option>-P</option>. (These options allow
system table modifications and prevent use of system indexes,
respectively.) 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 FORCE</> to force
reconstruction of all system indexes in the database. Then quit
the standalone server session and restart the real server.
</para>
<para>
See the <xref linkend="app-postgres"> reference page for more
information about how to interact with the stand-alone server
interface.
</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 included. This form of <command>REINDEX</>
can only be used in stand-alone mode (see above).
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>TABLE</literal></term>
<listitem>
<para>
Recreate all indexes of a specified table.
</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>
Force rebuild of system indexes. Without this key word,
<command>REINDEX</> skips system indexes that are not marked
invalid. <literal>FORCE</> is irrelevant for <command>REINDEX
INDEX</> or when reindexing user indexes.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Diagnostics</title>
<variablelist>
<varlistentry>
<term><computeroutput>REINDEX</computeroutput></term>
<listitem>
<para>
Message returned if the indexes were successfully recreated.
</para>
</listitem>
</varlistentry>
</variablelist>
</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 (this will only work in a stand-alone
server session):
<programlisting>
REINDEX DATABASE my_database FORCE;
</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:
-->