1
0
mirror of https://github.com/postgres/postgres.git synced 2025-07-30 11:03:19 +03:00

Rework 'MOVE ALL' to 'ALTER .. ALL IN TABLESPACE'

As 'ALTER TABLESPACE .. MOVE ALL' really didn't change the tablespace
but instead changed objects inside tablespaces, it made sense to
rework the syntax and supporting functions to operate under the
'ALTER (TABLE|INDEX|MATERIALIZED VIEW)' syntax and to be in
tablecmds.c.

Pointed out by Alvaro, who also suggested the new syntax.

Back-patch to 9.4.
This commit is contained in:
Stephen Frost
2014-08-21 19:06:17 -04:00
parent 9243417801
commit d9b2bc45cf
18 changed files with 305 additions and 392 deletions

View File

@ -25,6 +25,8 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable> RENA
ALTER INDEX [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable> SET TABLESPACE <replaceable class="PARAMETER">tablespace_name</replaceable>
ALTER INDEX [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable> SET ( <replaceable class="PARAMETER">storage_parameter</replaceable> = <replaceable class="PARAMETER">value</replaceable> [, ... ] )
ALTER INDEX [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable> RESET ( <replaceable class="PARAMETER">storage_parameter</replaceable> [, ... ] )
ALTER INDEX ALL IN TABLESPACE <replaceable class="PARAMETER">name</replaceable> [ OWNED BY <replaceable class="PARAMETER">role_name</replaceable> [, ... ] ]
SET TABLESPACE <replaceable class="PARAMETER">new_tablespace</replaceable> [ NOWAIT ]
</synopsis>
</refsynopsisdiv>
@ -63,6 +65,17 @@ ALTER INDEX [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable> RESE
<para>
This form changes the index's tablespace to the specified tablespace and
moves the data file(s) associated with the index to the new tablespace.
To change the tablespace of an index, you must own the index and have
<literal>CREATE</literal> privilege on the new tablespace.
All indexes in the current database in a tablespace can be moved by using
the <literal>ALL IN TABLESPACE</literal> form, which will lock all
indexes to be moved and then move each one. This form also supports
<literal>OWNED BY</literal>, which will only move indexes owned by the
roles specified. If the <literal>NOWAIT</literal> 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 <command>ALTER DATABASE</command> or explicit
<command>ALTER INDEX</command> invocations instead if desired.
See also
<xref linkend="SQL-CREATETABLESPACE">.
</para>

View File

@ -29,6 +29,8 @@ ALTER MATERIALIZED VIEW [ IF EXISTS ] <replaceable class="parameter">name</repla
RENAME TO <replaceable class="parameter">new_name</replaceable>
ALTER MATERIALIZED VIEW [ IF EXISTS ] <replaceable class="parameter">name</replaceable>
SET SCHEMA <replaceable class="parameter">new_schema</replaceable>
ALTER MATERIALIZED VIEW ALL IN TABLESPACE <replaceable class="parameter">name</replaceable> [ OWNED BY <replaceable class="PARAMETER">role_name</replaceable> [, ... ] ]
SET TABLESPACE <replaceable class="PARAMETER">new_tablespace</replaceable> [ NOWAIT ]
<phrase>where <replaceable class="PARAMETER">action</replaceable> is one of:</phrase>

View File

@ -31,6 +31,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
RENAME TO <replaceable class="PARAMETER">new_name</replaceable>
ALTER TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
SET SCHEMA <replaceable class="PARAMETER">new_schema</replaceable>
ALTER TABLE ALL IN TABLESPACE <replaceable class="PARAMETER">name</replaceable> [ OWNED BY <replaceable class="PARAMETER">role_name</replaceable> [, ... ] ]
SET TABLESPACE <replaceable class="PARAMETER">new_tablespace</replaceable> [ NOWAIT ]
<phrase>where <replaceable class="PARAMETER">action</replaceable> is one of:</phrase>
@ -597,6 +599,17 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
moves the data file(s) associated with the table to the new tablespace.
Indexes on the table, if any, are not moved; but they can be moved
separately with additional <literal>SET TABLESPACE</literal> commands.
All tables in the current database in a tablespace can be moved by using
the <literal>ALL IN TABLESPACE</literal> form, which will lock all tables
to be moved first and then move each one. This form also supports
<literal>OWNED BY</literal>, which will only move tables owned by the
roles specified. If the <literal>NOWAIT</literal> option is specified
then the command will fail if it is unable to acquire all of the locks
required immediately. Note that system catalogs are not moved by this
command, use <command>ALTER DATABASE</command> or explicit
<command>ALTER TABLE</command> invocations instead if desired. The
<literal>information_schema</literal> relations are not considered part
of the system catalogs and will be moved.
See also
<xref linkend="SQL-CREATETABLESPACE">.
</para>
@ -649,7 +662,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
</para>
<para>
All the actions except <literal>RENAME</literal> and <literal>SET SCHEMA</>
All the actions except <literal>RENAME</literal>,
<literal>SET TABLESPACE</literal> and <literal>SET SCHEMA</literal>
can be combined into
a list of multiple alterations to apply in parallel. For example, it
is possible to add several columns and/or alter the type of several
@ -659,8 +673,8 @@ ALTER TABLE [ IF EXISTS ] <replaceable class="PARAMETER">name</replaceable>
<para>
You must own the table to use <command>ALTER TABLE</>.
To change the schema of a table, you must also have
<literal>CREATE</literal> privilege on the new schema.
To change the schema or tablespace of a table, you must also have
<literal>CREATE</literal> privilege on the new schema or tablespace.
To add the table as a new child of a parent table, you must own the
parent table as well.
To alter the owner, you must also be a direct or indirect member of the new

View File

@ -25,7 +25,6 @@ ALTER TABLESPACE <replaceable>name</replaceable> RENAME TO <replaceable>new_name
ALTER TABLESPACE <replaceable>name</replaceable> OWNER TO <replaceable>new_owner</replaceable>
ALTER TABLESPACE <replaceable>name</replaceable> SET ( <replaceable class="PARAMETER">tablespace_option</replaceable> = <replaceable class="PARAMETER">value</replaceable> [, ... ] )
ALTER TABLESPACE <replaceable>name</replaceable> RESET ( <replaceable class="PARAMETER">tablespace_option</replaceable> [, ... ] )
ALTER TABLESPACE <replaceable>name</replaceable> MOVE { ALL | TABLES | INDEXES | MATERIALIZED VIEWS } [ OWNED BY <replaceable class="PARAMETER">role_name</replaceable> [, ...] ] TO <replaceable>new_tablespace</replaceable> [ NOWAIT ]
</synopsis>
</refsynopsisdiv>
@ -45,44 +44,6 @@ ALTER TABLESPACE <replaceable>name</replaceable> MOVE { ALL | TABLES | INDEXES |
(Note that superusers have these privileges automatically.)
</para>
<para>
<literal>ALTER TABLESPACE ... MOVE</literal> moves objects between
tablespaces. <literal>ALL</literal> will move all tables, indexes and
materialized views; specifying <literal>TABLES</literal> will move only
tables (but not their indexes), <literal>INDEXES</literal> will only move
indexes (including those underneath materialized views, but not tables),
and <literal>MATERIALIZED VIEWS</literal> 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
<literal>OWNED BY</literal>.
</para>
<para>
Users must have <literal>CREATE</literal> 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 <literal>ALTER TABLESPACE ... MOVE ALL</literal> 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 <literal>OWNED BY</literal> in
such cases, to restrict the set of objects moved to those with the required
rights.)
</para>
<para>
All objects to be moved will be locked immediately by the command. If the
<literal>NOWAIT</literal> is specified, it will cause the command to fail
if it is unable to acquire the locks.
</para>
<para>
System catalogs will not be moved by this command. To move a whole
database, use <command>ALTER DATABASE</command>, or call <command>ALTER
TABLE</command> on the individual system catalogs. Note that relations in
<literal>information_schema</literal> will be moved, just as any other
normal database objects, if the user is the superuser or considered an
owner of the relations in <literal>information_schema</literal>.
</para>
</refsect1>
<refsect1>
@ -136,38 +97,6 @@ ALTER TABLESPACE <replaceable>name</replaceable> MOVE { ALL | TABLES | INDEXES |
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">role_name</replaceable></term>
<listitem>
<para>
Role whose objects are to be moved.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term><replaceable class="parameter">new_tablespace</replaceable></term>
<listitem>
<para>
The name of the tablespace to move objects into. The user must have
<literal>CREATE</literal> 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.
</para>
</listitem>
</varlistentry>
<varlistentry>
<term>NOWAIT</term>
<listitem>
<para>
The <literal>NOWAIT</literal> option causes the <command>ALTER TABLESPACE</command> command to fail immediately
if it is unable to acquire the necessary lock on all of the objects being
moved.
</para>
</listitem>
</varlistentry>
</variablelist>
</refsect1>
@ -185,13 +114,6 @@ ALTER TABLESPACE index_space RENAME TO fast_raid;
Change the owner of tablespace <literal>index_space</literal>:
<programlisting>
ALTER TABLESPACE index_space OWNER TO mary;
</programlisting></para>
<para>
Move all of the objects from the default tablespace to
the <literal>fast_raid</literal> tablespace:
<programlisting>
ALTER TABLESPACE pg_default MOVE ALL TO fast_raid;
</programlisting></para>
</refsect1>

View File

@ -1224,7 +1224,10 @@
<listitem>
<para>
Allow moving groups of objects from one tablespace to another
using <xref linkend="SQL-ALTERTABLESPACE"> ... <literal>MOVE</>
using <literal>ALL IN TABLESPACE ... SET TABLESPACE</> with
<link linkend="SQL-ALTERTABLE"><command>ALTER TABLE</></link>
<link linkend="SQL-ALTERINDEX"><command>ALTER INDEX</></link> and
<link linkend="SQL-ALTERMATERIALIZEDVIEW"><command>ALTER MATERIALIZED VIEW</></link>
(Stephen Frost)
</para>
</listitem>