CREATE [ UNIQUE ] INDEX index_name ON table [ USING acc_method ] ( column [ ops_name ] [, ...] ) [ WHERE predicate ] CREATE [ UNIQUE ] INDEX index_name ON table [ USING acc_method ] ( func_name( column [, ... ]) [ ops_name ] ) [ WHERE predicate ]
Causes the system to check for duplicate values in the table when the index is created (if data already exist) and each time data is added. Attempts to insert or update data which would result in duplicate entries will generate an error.
The name of the index to be created.
The name of the table to be indexed.
The name of the access method to be used for the index. The default access method is BTREE. PostgreSQL provides four access methods for indexes:
an implementation of Lehman-Yao high-concurrency B-trees.
implements standard R-trees using Guttman's quadratic split algorithm.
an implementation of Litwin's linear hashing.
Generalized Index Search Trees.
The name of a column of the table.
An associated operator class. See below for details.
A function, which returns a value that can be indexed.
Defines the constraint expression for a partial index.
CREATE INDEX constructs an index index_name on the specified table.
Tip: Indexes are primarily used to enhance database performance. But inappropriate use will result in slower performance.
In the first syntax shown above, the key field(s) for the index are specified as column names. Multiple fields can be specified if the index access method supports multicolumn indexes.
In the second syntax shown above, an index is defined on the result of a user-specified function func_name applied to one or more columns of a single table. These functional indexes can be used to obtain fast access to data based on operators that would normally require some transformation to apply them to the base data.
PostgreSQL provides B-tree, R-tree, hash, and GiST access methods for indexes. The B-tree access method is an implementation of Lehman-Yao high-concurrency B-trees. The R-tree access method implements standard R-trees using Guttman's quadratic split algorithm. The hash access method is an implementation of Litwin's linear hashing. We mention the algorithms used solely to indicate that all of these access methods are fully dynamic and do not have to be optimized periodically (as is the case with, for example, static hash access methods).
When the WHERE clause is present, a partial index is created. A partial index is an index that contains entries for only a portion of a table, usually a portion that is somehow more interesting 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 WHERE with UNIQUE to enforce uniqueness over a subset of a table.
The expression used in the WHERE clause may refer only to columns of the underlying table (but it can use all columns, not only the one(s) being indexed). Presently, sub-SELECTs and aggregate expressions are also forbidden in WHERE.
All functions and operators used in an index definition must be cachable, that is, their results must depend only on their input arguments and never on any outside influence (such as the contents of another table or the current time). This restriction ensures that the behavior of the index is well-defined. To use a user-defined function in an index, remember to mark the function cachable when you create it.
Use DROP INDEX to remove an index.
The PostgreSQL query optimizer will consider using a B-tree index whenever an indexed attribute is involved in a comparison using one of: <, <=, =, >=, >
The PostgreSQL query optimizer will consider using an R-tree index whenever an indexed attribute is involved in a comparison using one of: <<, &<, &>, >>, @, ~=, &&
The PostgreSQL query optimizer will consider using a hash index whenever an indexed attribute is involved in a comparison using the = operator.
Currently, only the B-tree and gist access methods support multi-column indexes. Up to 16 keys may be specified by default (this limit can be altered when building PostgreSQL). Only B-tree currently supports unique indexes.
An operator class can be specified for each column of an index. The operator class identifies the operators to be used by the index for that column. For example, a B-tree index on four-byte integers would use the int4_ops class; this operator class includes comparison functions for four-byte integers. In practice the default operator class for the field's data type is usually sufficient. The main point of having operator classes is that for some data types, there could be more than one meaningful ordering. For example, we might want to sort a complex-number data type either by absolute value or by real part. We could do this by defining two operator classes for the data type and then selecting the proper class when making an index. There are also some operator classes with special purposes:
The operator classes box_ops and bigbox_ops both support R-tree indexes on the box data type. The difference between them is that bigbox_ops scales box coordinates down, to avoid floating-point exceptions from doing multiplication, addition, and subtraction on very large floating-point coordinates. (Note: this was true some time ago, but currently the two operator classes both use floating point and are effectively identical.)
The following query shows all defined operator classes:
SELECT am.amname AS acc_method, opc.opcname AS ops_name, opr.oprname AS ops_comp FROM pg_am am, pg_opclass opc, pg_amop amop, pg_operator opr WHERE opc.opcamid = am.oid AND amop.amopclaid = opc.oid AND amop.amopopr = opr.oid ORDER BY acc_method, ops_name, ops_comp;
To create a B-tree index on the field title in the table films:
CREATE UNIQUE INDEX title_idx ON films (title);