Changes the definition of an index.
ALTER INDEX [ IF EXISTS ] <name> RENAME TO <new_name>
ALTER INDEX [ IF EXISTS ] <name> SET TABLESPACE <tablespace_name>
ALTER INDEX <name> ATTACH PARTITION <index_name>
ALTER INDEX <name DEPENDS ON EXTENSION <extension_name>
ALTER INDEX [ IF EXISTS ] <name> SET ( <storage_parameter> [= <value>] [, ...] )
ALTER INDEX [ IF EXISTS ] <name> RESET ( <storage_parameter> [, ...] )
ALTER INDEX [ IF EXISTS ] <name> ALTER [ COLUMN ] <column_number>
SET STATISTICS <integer>
ALTER INDEX ALL IN TABLESPACE <name> [ OWNED BY <role_name> [, ... ] ]
SET TABLESPACE <new_tablespace> [ NOWAIT ]
ALTER INDEX
changes the definition of an existing index. There are several subforms described below. Note that the lock level required may differ for each subform. An ACCESS EXCLUSIVE
lock is held unless explicitly noted. When multiple subcommands are listed, the lock held will be the strictest one required from any subcommand.
UNIQUE
,
PRIMARY KEY
, or
EXCLUDE
), the constraint is renamed as well. There is no effect on the stored data.
SHARE UPDATE EXCLUSIVE
lock.
CREATE
privilege on the new tablespace. All indexes in the current database in a tablespace can be moved by using the
ALL IN TABLESPACE
form, which will lock all indexes to be moved and then move each one. This form also supports
OWNED BY
, which will only move indexes owned by the roles specified. If the
NOWAIT
option is specified then the command will fail if it is unable to acquire all of the locks required immediately. Note that system catalogs will not be moved by this command, use
ALTER DATABASE
or explicit
ALTER INDEX
invocations instead if desired. See also
CREATE TABLESPACE.
SET
, a
REINDEX
may be needed to update the index entirely.
ANALYZE
operations, though can be used only on index columns that are defined as an expression. Since expressions lack a unique name, we refer to them using the ordinal number of the index column. The target can be set in the range 0 to 10000; alternatively, set it to
-1
to revert to using the system default statistics target (
default_statistics_target).
These operations are also possible using ALTER TABLE. ALTER INDEX
is in fact just an alias for the forms of ALTER TABLE
that apply to indexes.
There was formerly an ALTER INDEX OWNER
variant, but this is now ignored (with a warning). An index cannot have an owner different from its table's owner. Changing the table's owner automatically changes the index as well.
Changing any part of a system catalog index is not permitted.
To rename an existing index:
ALTER INDEX distributors RENAME TO suppliers;
To move an index to a different tablespace:
ALTER INDEX distributors SET TABLESPACE fasttablespace;
To change an index's fill factor (assuming that the index method supports it):
ALTER INDEX distributors SET (fillfactor = 75);
REINDEX INDEX distributors;
Set the statistics-gathering target for an expression index:
CREATE INDEX coord_idx ON measured (x, y, (z + t));
ALTER INDEX coord_idx ALTER COLUMN 3 SET STATISTICS 1000;
ALTER INDEX
is a Greenplum Database extension to the SQL standard.
CREATE INDEX, REINDEX, ALTER TABLE
Parent topic: SQL Commands