ALTER TABLESPACE
ALTER TABLESPACE
7
SQL - Language Statements
ALTER TABLESPACE
change the definition of a tablespace or affect objects of a tablespace
ALTER TABLESPACE name RENAME TO new_name
ALTER TABLESPACE name OWNER TO new_owner
ALTER TABLESPACE name SET ( tablespace_option = value [, ... ] )
ALTER TABLESPACE name RESET ( tablespace_option [, ... ] )
ALTER TABLESPACE name MOVE { ALL | TABLES | INDEXES | MATERIALIZED VIEWS } [ OWNED BY role_name [, ...] ] TO new_tablespace [ NOWAIT ]
Description
ALTER TABLESPACE can be used to change the definition of
a tablespace or to migrate objects in the current database between
tablespaces.
You must own the tablespace to change the definition of a tablespace.
To alter the owner, you must also be a direct or indirect member of the new
owning role.
(Note that superusers have these privileges automatically.)
ALTER TABLESPACE ... MOVE moves objects between
tablespaces. ALL will move all tables, indexes and
materialized views; specifying TABLES will move only
tables (but not their indexes), INDEXES will only move
indexes (including those underneath materialized views, but not tables),
and MATERIALIZED VIEWS will only move the table relation
of the materialized view (but no indexes associated with it). Users can
also specify a list of roles whose objects are to be moved, using
OWNED BY.
Users must have CREATE rights on the new tablespace and
be considered an owner (either directly or indirectly) of all objects to be
moved. Note that the superuser is considered an owner of all objects, and
therefore an ALTER TABLESPACE ... MOVE ALL issued by the
superuser will move all objects in the current database that are in the
tablespace. (Attempting to move objects without the required rights will
result in an error. Non-superusers can use OWNED BY in
such cases, to restrict the set of objects moved to those with the required
rights.)
All objects to be moved will be locked immediately by the command. If the
NOWAIT is specified, it will cause the command to fail
if it is unable to acquire the locks.
System catalogs will not be moved by this command. To move a whole
database, use ALTER DATABASE, or call ALTER
TABLE on the individual system catalogs. Note that relations in
information_schema will be moved, just as any other
normal database objects, if the user is the superuser or considered an
owner of the relations in information_schema.
Parameters
name
The name of an existing tablespace.
new_name
The new name of the tablespace. The new name cannot
begin with pg_, as such names
are reserved for system tablespaces.
new_owner
The new owner of the tablespace.
tablespace_option
A tablespace parameter to be set or reset. Currently, the only
available parameters are seq_page_cost> and
random_page_cost>. Setting either value for a particular
tablespace will override the planner's usual estimate of the cost of
reading pages from tables in that tablespace, as established by
the configuration parameters of the same name (see
,
). This may be useful if one
tablespace is located on a disk which is faster or slower than the
remainder of the I/O subsystem.
role_name
Role whose objects are to be moved.
new_tablespace
The name of the tablespace to move objects into. The user must have
CREATE rights on the new tablespace to move objects into that
tablespace, unless the tablespace being moved into is the default
tablespace for the database connected to.
NOWAIT
The NOWAIT option causes the ALTER TABLESPACE command to fail immediately
if it is unable to acquire the necessary lock on all of the objects being
moved.
Examples
Rename tablespace index_space to fast_raid:
ALTER TABLESPACE index_space RENAME TO fast_raid;
Change the owner of tablespace index_space:
ALTER TABLESPACE index_space OWNER TO mary;
Move all of the objects from the default tablespace to
the fast_raid tablespace:
ALTER TABLESPACE pg_default MOVE ALL TO fast_raid;
Compatibility
There is no ALTER TABLESPACE statement in
the SQL standard.
See Also