<!-- doc/src/sgml/indices.sgml -->
<chapter id="indexes">
<title>Indexes</title>
<indexterm zone="indexes">
<primary>index</primary>
</indexterm>
<para>
Indexes are a common way to enhance database performance. An index
allows the database server to find and retrieve specific rows much
faster than it could do without an index. But indexes also add
overhead to the database system as a whole, so they should be used
sensibly.
</para>
<sect1 id="indexes-intro">
<title>Introduction</title>
<para>
Suppose we have a table similar to this:
<programlisting>
CREATE TABLE test1 (
id integer,
content varchar
);
</programlisting>
and the application issues many queries of the form:
<programlisting>
SELECT content FROM test1 WHERE id = <replaceable>constant</replaceable>;
</programlisting>
With no advance preparation, the system would have to scan the entire
<structname>test1</structname> table, row by row, to find all
matching entries. If there are many rows in
<structname>test1</structname> and only a few rows (perhaps zero
or one) that would be returned by such a query, this is clearly an
inefficient method. But if the system has been instructed to maintain an
index on the <structfield>id</structfield> column, it can use a more
efficient method for locating matching rows. For instance, it
might only have to walk a few levels deep into a search tree.
</para>
<para>
A similar approach is used in most non-fiction books: terms and
concepts that are frequently looked up by readers are collected in
an alphabetic index at the end of the book. The interested reader
can scan the index relatively quickly and flip to the appropriate
page(s), rather than having to read the entire book to find the
material of interest. Just as it is the task of the author to
anticipate the items that readers are likely to look up,
it is the task of the database programmer to foresee which indexes
will be useful.
</para>
<para>
The following command can be used to create an index on the
<structfield>id</structfield> column, as discussed:
<programlisting>
CREATE INDEX test1_id_index ON test1 (id);
</programlisting>
The name <structname>test1_id_index</structname> can be chosen
freely, but you should pick something that enables you to remember
later what the index was for.
</para>
<para>
To remove an index, use the <command>DROP INDEX</command> command.
Indexes can be added to and removed from tables at any time.
</para>
<para>
Once an index is created, no further intervention is required: the
system will update the index when the table is modified, and it will
use the index in queries when it thinks doing so would be more efficient
than a sequential table scan. But you might have to run the
<command>ANALYZE</command> command regularly to update
statistics to allow the query planner to make educated decisions.
See <xref linkend="performance-tips"/> for information about
how to find out whether an index is used and when and why the
planner might choose <emphasis>not</emphasis> to use an index.
</para>
<para>
Indexes can also benefit <command>UPDATE</command> and
<command>DELETE</command> commands with search conditions.
Indexes can moreover be used in join searches. Thus,
an index defined on a column that is part of a join condition can
also significantly speed up queries with joins.
</para>
<para>
In general, <productname>PostgreSQL</productname> indexes can be used
to optimize queries that contain one or more <literal>WHERE</literal>
or <literal>JOIN</literal> clauses of the form
<synopsis>
<replaceable>indexed-column</replaceable> <replaceable>indexable-operator</replaceable> <replaceable>comparison-value</replaceable>
</synopsis>
Here, the <replaceable>indexed-column</replaceable> is whatever
column or expression the index has been defined on.
The <replaceable>indexable-operator</replaceable>