PostgreSQL/doc/src/sgml/ref/drop_index.sgml
Tom Lane 94c014b532 Fix assorted bugs in CREATE/DROP INDEX CONCURRENTLY.
Commit 8cb53654dbdb4c386369eb988062d0bbb6de725e, which introduced DROP
INDEX CONCURRENTLY, managed to break CREATE INDEX CONCURRENTLY via a poor
choice of catalog state representation.  The pg_index state for an index
that's reached the final pre-drop stage was the same as the state for an
index just created by CREATE INDEX CONCURRENTLY.  This meant that the
(necessary) change to make RelationGetIndexList ignore about-to-die indexes
also made it ignore freshly-created indexes; which is catastrophic because
the latter do need to be considered in HOT-safety decisions.  Failure to
do so leads to incorrect index entries and subsequently wrong results from
queries depending on the concurrently-created index.

To fix, make the final state be indisvalid = true and indisready = false,
which is otherwise nonsensical.  This is pretty ugly but we can't add
another column without forcing initdb, and it's too late for that in 9.2.
(There's a cleaner fix in HEAD.)

In addition, change CREATE/DROP INDEX CONCURRENTLY so that the pg_index
flag changes they make without exclusive lock on the index are made via
heap_inplace_update() rather than a normal transactional update.  The
latter is not very safe because moving the pg_index tuple could result in
concurrent SnapshotNow scans finding it twice or not at all, thus possibly
resulting in index corruption.  This is a pre-existing bug in CREATE INDEX
CONCURRENTLY, which was copied into the DROP code.

In addition, fix various places in the code that ought to check to make
sure that the indexes they are manipulating are valid and/or ready as
appropriate.  These represent bugs that have existed since 8.2, since
a failed CREATE INDEX CONCURRENTLY could leave a corrupt or invalid
index behind, and we ought not try to do anything that might fail with
such an index.

Also fix RelationReloadIndexInfo to ensure it copies all the pg_index
columns that are allowed to change after initial creation.  Previously we
could have been left with stale values of some fields in an index relcache
entry.  It's not clear whether this actually had any user-visible
consequences, but it's at least a bug waiting to happen.

In addition, do some code and docs review for DROP INDEX CONCURRENTLY;
some cosmetic code cleanup but mostly addition and revision of comments.

Portions of this need to be back-patched even further, but I'll work
on that separately.

Problem reported by Amit Kapila, diagnosis by Pavan Deolasee,
fix by Tom Lane and Andres Freund.
2012-11-29 10:37:13 -05:00

134 lines
3.3 KiB
Plaintext

<!--
doc/src/sgml/ref/drop_index.sgml
PostgreSQL documentation
-->
<refentry id="SQL-DROPINDEX">
<refmeta>
<refentrytitle>DROP INDEX</refentrytitle>
<manvolnum>7</manvolnum>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>DROP INDEX</refname>
<refpurpose>remove an index</refpurpose>
</refnamediv>
<indexterm zone="sql-dropindex">
<primary>DROP INDEX</primary>
</indexterm>
<refsynopsisdiv>
<synopsis>
DROP INDEX [ CONCURRENTLY ] [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable> [, ...] [ CASCADE | RESTRICT ]
</synopsis>
</refsynopsisdiv>
<refsect1>
<title>Description</title>
<para>
<command>DROP INDEX</command> drops an existing index from the database
system. To execute this command you must be the owner of
the index.
</para>
</refsect1>
<refsect1>
<title>Parameters</title>
<variablelist>
<varlistentry>
<term><literal>CONCURRENTLY</literal></term>
<listitem>
<para>
Drop the index without locking out concurrent selects, inserts, updates,
and deletes on the index's table. A normal <command>DROP INDEX</>
acquires exclusive lock on the table, blocking other accesses until the
index drop can be completed. With this option, the command instead
waits until conflicting transactions have completed.
</para>
<para>
There are several caveats to be aware of when using this option.
Only one index name can be specified, and the <literal>CASCADE</> option
is not supported. (Thus, an index that supports a <literal>UNIQUE</> or
<literal>PRIMARY KEY</> constraint cannot be dropped this way.)
Also, regular <command>DROP INDEX</> commands can be
performed within a transaction block, but
<command>DROP INDEX CONCURRENTLY</> cannot.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>IF EXISTS</literal></term>
<listitem>
<para>
Do not throw an error if the index does not exist. A notice is issued
in this case.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="PARAMETER">name</replaceable></term>
<listitem>
<para>
The name (optionally schema-qualified) of an index to remove.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>CASCADE</literal></term>
<listitem>
<para>
Automatically drop objects that depend on the index.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><literal>RESTRICT</literal></term>
<listitem>
<para>
Refuse to drop the index if any objects depend on it. This is
the default.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
<refsect1>
<title>Examples</title>
<para>
This command will remove the index <literal>title_idx</literal>:
<programlisting>
DROP INDEX title_idx;
</programlisting></para>
</refsect1>
<refsect1>
<title>Compatibility</title>
<para>
<command>DROP INDEX</command> is a
<productname>PostgreSQL</productname> language extension. There
are no provisions for indexes in the SQL standard.
</para>
</refsect1>
<refsect1>
<title>See Also</title>
<simplelist type="inline">
<member><xref linkend="sql-createindex"></member>
</simplelist>
</refsect1>
</refentry>