<!--
doc/src/sgml/ref/create_index.sgml
PostgreSQL documentation
-->
<refentry id="sql-createindex">
<indexterm zone="sql-createindex">
<primary>CREATE INDEX</primary>
</indexterm>
<refmeta>
<refentrytitle>CREATE INDEX</refentrytitle>
<manvolnum>7</manvolnum>
<refmiscinfo>SQL - Language Statements</refmiscinfo>
</refmeta>
<refnamediv>
<refname>CREATE INDEX</refname>
<refpurpose>define a new index</refpurpose>
</refnamediv>
<refsynopsisdiv>
<synopsis>
CREATE [ UNIQUE ] INDEX [ CONCURRENTLY ] [ [ IF NOT EXISTS ] <replaceable class="parameter">name</replaceable> ] ON [ ONLY ] <replaceable class="parameter">table_name</replaceable> [ USING <replaceable class="parameter">method</replaceable> ]
( { <replaceable class="parameter">column_name</replaceable> | ( <replaceable class="parameter">expression</replaceable> ) } [ COLLATE <replaceable class="parameter">collation</replaceable> ] [ <replaceable class="parameter">opclass</replaceable> [ ( <replaceable class="parameter">opclass_parameter</replaceable> = <replaceable class="parameter">value</replaceable> [, ... ] ) ] ] [ ASC | DESC ] [ NULLS { FIRST | LAST } ] [, ...] )
[ INCLUDE ( <replaceable class="parameter">column_name</replaceable> [, ...] ) ]
[ NULLS [ NOT ] DISTINCT ]
[ WITH ( <replaceable class="parameter">storage_parameter</replaceable> [= <replaceable class="parameter">value</replaceable>] [, ... ] ) ]
[ TABLESPACE <replaceable class="parameter">tablespace_name</replaceable> ]
[ WHERE <replaceable class="parameter">predicate</replaceable> ]
</synopsis>
</refsynopsisdiv>
<refsect1>
<title>Description</title>
<para>
<command>CREATE INDEX</command> constructs an index on the specified column(s)
of the specified relation, which can be a table or a materialized view.
Indexes are primarily used to enhance database performance (though
inappropriate use can result in slower performance).
</para>
<para>
The key field(s) for the index are specified as column names,
or alternatively as expressions written in parentheses.
Multiple fields can be specified if the index method supports
multicolumn indexes.
</para>
<para>
An index field can be an expression computed from the values of
one or more columns of the table row. This feature can be used
to obtain fast access to data based on some transformation of
the basic data. For example, an index computed on
<literal>upper(col)</literal> would allow the clause
<literal>WHERE upper(col) = 'JIM'</literal> to use an index.
</para>
<para>
<productname>PostgreSQL</productname> provides the index methods
B-tree, hash, GiST, SP-GiST, GIN, and BRIN. Users can also define their own
index methods, but that is fairly complicated.
</para>
<para>
When the <literal>WHERE</literal> clause is present, a
<firstterm>partial index</firstterm> is created.
A partial index is an index that contains entries for only a portion of
a table, usually a portion that is more useful for indexing than the
rest of the table. For example, if you have a table that contains both
billed and unbilled orders where the unbilled orders take up a small
fraction of the total table and yet that is an often used section, you
can improve performance by creating an index on just that portion.
Another possible application is to use <literal>WHERE</literal> with
<literal>UNIQUE</literal> to enforce uniqueness over a subset of a
table. See <xref linkend="indexes-partial"/> for more discussion.
</para>
<para>
The expression used in the <literal>WHERE</literal> clause can refer
only to columns of the underlying table, but it can use all columns,
not just the ones being indexed. Presently, subqueries and
aggregate expressions are also forbidden in <literal>WHERE</literal>.
The same restrictions apply to index fields that are expressions.
</para>
<para>
All functions and operators used in an