<refnamediv>
<refname>ALTER TABLESPACE</refname>
- <refpurpose>change the definition of a tablespace</refpurpose>
+ <refpurpose>change the definition of a tablespace or affect objects of a tablespace</refpurpose>
</refnamediv>
<indexterm zone="sql-altertablespace">
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 } TO <replaceable>new_tablespace</replaceable> [ NOWAIT ]
</synopsis>
</refsynopsisdiv>
<title>Description</title>
<para>
- <command>ALTER TABLESPACE</command> changes the definition of
- a tablespace.
+ <command>ALTER TABLESPACE</command> can be used to change the definition of
+ a tablespace or to migrate all of the objects in the current database which
+ are owned by the user out of a given tablespace.
</para>
<para>
- You must own the tablespace to use <command>ALTER TABLESPACE</>.
+ 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.)
+
+ Users may use ALTER TABLESPACE ... MOVE to move either ALL of their objects,
+ or just TABLES, INDEXES, or MATERIALIZED VIEWS, but they must have CREATE
+ rights on the new tablespace and only objects, directly or indirectly, owned
+ by the user will 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 which are in the
+ tablespace.
+
+ All objects to be moved will be locked immediately by the command. The
+ NOWAIT option, if specified, will cause the command to fail if it is unable
+ to acquire the locks.
+
+ System catalogs will not be moved by this command- individuals wishing to
+ move a whole database should use ALTER DATABASE, or call ALTER TABLE 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>
</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
+ 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.
+ </para>
+ </listitem>
+ </varlistentry>
+
+ <varlistentry>
+ <term><replaceable class="parameter">NOWAIT</replaceable></term>
+ <listitem>
+ <para>
+ 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
+ move.
+ </para>
+ </listitem>
+ </varlistentry>
+
</variablelist>
</refsect1>
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 which I own from the default tablespace to
+ the <literal>fast_raid</literal> tablespace:
+<programlisting>
+ALTER TABLESPACE pg_default MOVE ALL TO fast_raid;
</programlisting></para>
</refsect1>
#include "catalog/catalog.h"
#include "catalog/dependency.h"
#include "catalog/indexing.h"
+#include "catalog/namespace.h"
#include "catalog/objectaccess.h"
+#include "catalog/pg_namespace.h"
#include "catalog/pg_tablespace.h"
#include "commands/comment.h"
#include "commands/seclabel.h"
+#include "commands/tablecmds.h"
#include "commands/tablespace.h"
#include "common/relpath.h"
#include "miscadmin.h"
#include "postmaster/bgwriter.h"
#include "storage/fd.h"
+#include "storage/lmgr.h"
#include "storage/standby.h"
#include "utils/acl.h"
#include "utils/builtins.h"
#include "utils/fmgroids.h"
#include "utils/guc.h"
+#include "utils/lsyscache.h"
#include "utils/memutils.h"
#include "utils/rel.h"
#include "utils/tqual.h"
return tablespaceoid;
}
+/*
+ * Alter table space move
+ *
+ * Allows a user to move all of their objects in a given tablespace in the
+ * current database to another tablespace. Only objects which the user is
+ * considered to be an owner of are moved and the user must have CREATE rights
+ * on the new tablespace. These checks should mean that ALTER TABLE will never
+ * fail due to permissions, but note that permissions will also be checked at
+ * that level. Objects can be ALL, TABLES, INDEXES, or MATERIALIZED VIEWS.
+ *
+ * All to-be-moved objects are locked first. If NOWAIT is specified and the
+ * lock can't be acquired then we ereport(ERROR).
+ */
+Oid
+AlterTableSpaceMove(AlterTableSpaceMoveStmt *stmt)
+{
+ List *relations = NIL;
+ ListCell *l;
+ ScanKeyData key[1];
+ Relation rel;
+ HeapScanDesc scan;
+ HeapTuple tuple;
+ Oid orig_tablespaceoid;
+ Oid new_tablespaceoid;
+
+ /* Ensure we were not asked to move something we can't */
+ if (!stmt->move_all && stmt->objtype != OBJECT_TABLE &&
+ stmt->objtype != OBJECT_INDEX && stmt->objtype != OBJECT_MATVIEW)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+ errmsg("only tables, indexes, and materialized views exist in tablespaces")));
+
+ /* Get the orig and new tablespace OIDs */
+ orig_tablespaceoid = get_tablespace_oid(stmt->orig_tablespacename, false);
+ new_tablespaceoid = get_tablespace_oid(stmt->new_tablespacename, false);
+
+ /* Can't move shared relations in to or out of pg_global */
+ /* This is also checked by ATExecSetTableSpace, but nice to stop earlier */
+ if (orig_tablespaceoid == GLOBALTABLESPACE_OID ||
+ new_tablespaceoid == GLOBALTABLESPACE_OID)
+ ereport(ERROR,
+ (errcode(ERRCODE_INVALID_PARAMETER_VALUE),
+ errmsg("cannot move relations in to or out of pg_global tablespace")));
+
+ /*
+ * Must have CREATE rights on the new tablespace, unless it is the
+ * database default tablespace (which all users implicitly have CREATE
+ * rights on).
+ */
+ if (OidIsValid(new_tablespaceoid) && new_tablespaceoid != MyDatabaseTableSpace)
+ {
+ AclResult aclresult;
+
+ aclresult = pg_tablespace_aclcheck(new_tablespaceoid, GetUserId(),
+ ACL_CREATE);
+ if (aclresult != ACLCHECK_OK)
+ aclcheck_error(aclresult, ACL_KIND_TABLESPACE,
+ get_tablespace_name(new_tablespaceoid));
+ }
+
+ /*
+ * Now that the checks are done, check if we should set either to
+ * InvalidOid because it is our database's default tablespace.
+ */
+ if (orig_tablespaceoid == MyDatabaseTableSpace)
+ orig_tablespaceoid = InvalidOid;
+
+ if (new_tablespaceoid == MyDatabaseTableSpace)
+ new_tablespaceoid = InvalidOid;
+
+ /* no-op */
+ if (orig_tablespaceoid == new_tablespaceoid)
+ return new_tablespaceoid;
+
+ /*
+ * Walk the list of objects in the tablespace and move them. This will
+ * only find objects in our database, of course.
+ */
+ ScanKeyInit(&key[0],
+ Anum_pg_class_reltablespace,
+ BTEqualStrategyNumber, F_OIDEQ,
+ ObjectIdGetDatum(orig_tablespaceoid));
+
+ rel = heap_open(RelationRelationId, AccessShareLock);
+ scan = heap_beginscan_catalog(rel, 1, key);
+ while ((tuple = heap_getnext(scan, ForwardScanDirection)) != NULL)
+ {
+ Oid relOid = HeapTupleGetOid(tuple);
+ Form_pg_class relForm;
+
+ relForm = (Form_pg_class) GETSTRUCT(tuple);
+
+ /*
+ * Do not move objects in pg_catalog as part of this, if an admin
+ * really wishes to do so, they can issue the individual ALTER
+ * commands directly.
+ *
+ * Also, explicitly avoid any shared tables, temp tables, or TOAST
+ * (TOAST will be moved with the main table).
+ */
+ if (IsSystemNamespace(relForm->relnamespace) || relForm->relisshared ||
+ isAnyTempNamespace(relForm->relnamespace) ||
+ relForm->relnamespace == PG_TOAST_NAMESPACE)
+ continue;
+
+ /*
+ * Only move objects that we are considered an owner of and only
+ * objects which can actually have a tablespace.
+ */
+ if (!pg_class_ownercheck(relOid, GetUserId()) ||
+ (relForm->relkind != RELKIND_RELATION &&
+ relForm->relkind != RELKIND_INDEX &&
+ relForm->relkind != RELKIND_MATVIEW))
+ continue;
+
+ /* Check if we were asked to only move a certain type of object */
+ if (!stmt->move_all &&
+ ((stmt->objtype == OBJECT_TABLE &&
+ relForm->relkind != RELKIND_RELATION) ||
+ (stmt->objtype == OBJECT_INDEX &&
+ relForm->relkind != RELKIND_INDEX) ||
+ (stmt->objtype == OBJECT_MATVIEW &&
+ relForm->relkind != RELKIND_MATVIEW)))
+ continue;
+
+ if (stmt->nowait &&
+ !ConditionalLockRelationOid(relOid, AccessExclusiveLock))
+ ereport(ERROR,
+ (errcode(ERRCODE_OBJECT_IN_USE),
+ errmsg("aborting due to \"%s\".\"%s\" --- lock not available",
+ get_namespace_name(relForm->relnamespace),
+ NameStr(relForm->relname))));
+ else
+ LockRelationOid(relOid, AccessExclusiveLock);
+
+ /* Add to our list of objects to move */
+ relations = lappend_oid(relations, relOid);
+ }
+
+ heap_endscan(scan);
+ heap_close(rel, AccessShareLock);
+
+ if (relations == NIL)
+ ereport(NOTICE,
+ (errcode(ERRCODE_NO_DATA_FOUND),
+ errmsg("no matching relations in tablespace \"%s\" found",
+ orig_tablespaceoid == InvalidOid ? "(database default)" :
+ get_tablespace_name(orig_tablespaceoid))));
+
+ /* Everything is locked, loop through and move all of the relations. */
+ foreach(l, relations)
+ {
+ List *cmds = NIL;
+ AlterTableCmd *cmd = makeNode(AlterTableCmd);
+
+ cmd->subtype = AT_SetTableSpace;
+ cmd->name = stmt->new_tablespacename;
+
+ cmds = lappend(cmds, cmd);
+
+ AlterTableInternal(lfirst_oid(l), cmds, false);
+ }
+
+ return new_tablespaceoid;
+}
+
/*
* Routines for handling the GUC variable 'default_tablespace'.
*/
return newnode;
}
+static AlterTableSpaceMoveStmt *
+_copyAlterTableSpaceMoveStmt(const AlterTableSpaceMoveStmt *from)
+{
+ AlterTableSpaceMoveStmt *newnode = makeNode(AlterTableSpaceMoveStmt);
+
+ COPY_STRING_FIELD(orig_tablespacename);
+ COPY_STRING_FIELD(new_tablespacename);
+ COPY_SCALAR_FIELD(nowait);
+
+ return newnode;
+}
+
static CreateExtensionStmt *
_copyCreateExtensionStmt(const CreateExtensionStmt *from)
{
case T_AlterTableSpaceOptionsStmt:
retval = _copyAlterTableSpaceOptionsStmt(from);
break;
+ case T_AlterTableSpaceMoveStmt:
+ retval = _copyAlterTableSpaceMoveStmt(from);
+ break;
case T_CreateExtensionStmt:
retval = _copyCreateExtensionStmt(from);
break;
return true;
}
+static bool
+_equalAlterTableSpaceMoveStmt(const AlterTableSpaceMoveStmt *a,
+ const AlterTableSpaceMoveStmt *b)
+{
+ COMPARE_STRING_FIELD(orig_tablespacename);
+ COMPARE_STRING_FIELD(new_tablespacename);
+ COMPARE_SCALAR_FIELD(nowait);
+
+ return true;
+}
+
static bool
_equalCreateExtensionStmt(const CreateExtensionStmt *a, const CreateExtensionStmt *b)
{
case T_AlterTableSpaceOptionsStmt:
retval = _equalAlterTableSpaceOptionsStmt(a, b);
break;
+ case T_AlterTableSpaceMoveStmt:
+ retval = _equalAlterTableSpaceMoveStmt(a, b);
+ break;
case T_CreateExtensionStmt:
retval = _equalCreateExtensionStmt(a, b);
break;
UNTIL UPDATE USER USING
VACUUM VALID VALIDATE VALIDATOR VALUE_P VALUES VARCHAR VARIADIC VARYING
- VERBOSE VERSION_P VIEW VOLATILE
+ VERBOSE VERSION_P VIEW VIEWS VOLATILE
WHEN WHERE WHITESPACE_P WINDOW WITH WITHIN WITHOUT WORK WRAPPER WRITE
n->missing_ok = false;
$$ = (Node *)n;
}
+ | ALTER TABLESPACE name MOVE ALL TO name opt_nowait
+ {
+ AlterTableSpaceMoveStmt *n =
+ makeNode(AlterTableSpaceMoveStmt);
+ n->orig_tablespacename = $3;
+ n->new_tablespacename = $7;
+ n->nowait = $8;
+ n->move_all = true;
+ $$ = (Node *)n;
+ }
+ | ALTER TABLESPACE name MOVE TABLES TO name opt_nowait
+ {
+ AlterTableSpaceMoveStmt *n =
+ makeNode(AlterTableSpaceMoveStmt);
+ n->orig_tablespacename = $3;
+ n->new_tablespacename = $7;
+ n->nowait = $8;
+ n->objtype = OBJECT_TABLE;
+ n->move_all = false;
+ $$ = (Node *)n;
+ }
+ | ALTER TABLESPACE name MOVE INDEXES TO name opt_nowait
+ {
+ AlterTableSpaceMoveStmt *n =
+ makeNode(AlterTableSpaceMoveStmt);
+ n->orig_tablespacename = $3;
+ n->new_tablespacename = $7;
+ n->nowait = $8;
+ n->objtype = OBJECT_INDEX;
+ n->move_all = false;
+ $$ = (Node *)n;
+ }
+ | ALTER TABLESPACE name MOVE MATERIALIZED VIEWS TO name opt_nowait
+ {
+ AlterTableSpaceMoveStmt *n =
+ makeNode(AlterTableSpaceMoveStmt);
+ n->orig_tablespacename = $3;
+ n->new_tablespacename = $8;
+ n->nowait = $9;
+ n->objtype = OBJECT_MATVIEW;
+ n->move_all = false;
+ $$ = (Node *)n;
+ }
| ALTER TABLESPACE name SET reloptions
{
AlterTableSpaceOptionsStmt *n =
| VARYING
| VERSION_P
| VIEW
+ | VIEWS
| VOLATILE
| WHITESPACE_P
| WITHIN
case T_AlterUserMappingStmt:
case T_DropUserMappingStmt:
case T_AlterTableSpaceOptionsStmt:
+ case T_AlterTableSpaceMoveStmt:
case T_CreateForeignTableStmt:
case T_SecLabelStmt:
PreventCommandIfReadOnly(CreateCommandTag(parsetree));
AlterTableSpaceOptions((AlterTableSpaceOptionsStmt *) parsetree);
break;
+ case T_AlterTableSpaceMoveStmt:
+ /* no event triggers for global objects */
+ AlterTableSpaceMove((AlterTableSpaceMoveStmt *) parsetree);
+ break;
+
case T_TruncateStmt:
ExecuteTruncate((TruncateStmt *) parsetree);
break;
tag = "ALTER TABLESPACE";
break;
+ case T_AlterTableSpaceMoveStmt:
+ tag = "ALTER TABLESPACE";
+ break;
+
case T_CreateExtensionStmt:
tag = "CREATE EXTENSION";
break;
lev = LOGSTMT_DDL;
break;
+ case T_AlterTableSpaceMoveStmt:
+ lev = LOGSTMT_DDL;
+ break;
+
case T_CreateExtensionStmt:
case T_AlterExtensionStmt:
case T_AlterExtensionContentsStmt:
extern void DropTableSpace(DropTableSpaceStmt *stmt);
extern Oid RenameTableSpace(const char *oldname, const char *newname);
extern Oid AlterTableSpaceOptions(AlterTableSpaceOptionsStmt *stmt);
+extern Oid AlterTableSpaceMove(AlterTableSpaceMoveStmt *stmt);
extern void TablespaceCreateDbspace(Oid spcNode, Oid dbNode, bool isRedo);
T_AlterUserMappingStmt,
T_DropUserMappingStmt,
T_AlterTableSpaceOptionsStmt,
+ T_AlterTableSpaceMoveStmt,
T_SecLabelStmt,
T_CreateForeignTableStmt,
T_CreateExtensionStmt,
bool isReset;
} AlterTableSpaceOptionsStmt;
+typedef struct AlterTableSpaceMoveStmt
+{
+ NodeTag type;
+ char *orig_tablespacename;
+ char *new_tablespacename;
+ ObjectType objtype;
+ bool nowait;
+ bool move_all;
+} AlterTableSpaceMoveStmt;
+
/* ----------------------
* Create/Alter Extension Statements
* ----------------------
PG_KEYWORD("verbose", VERBOSE, TYPE_FUNC_NAME_KEYWORD)
PG_KEYWORD("version", VERSION_P, UNRESERVED_KEYWORD)
PG_KEYWORD("view", VIEW, UNRESERVED_KEYWORD)
+PG_KEYWORD("views", VIEWS, UNRESERVED_KEYWORD)
PG_KEYWORD("volatile", VOLATILE, UNRESERVED_KEYWORD)
PG_KEYWORD("when", WHEN, RESERVED_KEYWORD)
PG_KEYWORD("where", WHERE, RESERVED_KEYWORD)
ALTER TABLESPACE testspace RENAME TO testspace_renamed;
-DROP SCHEMA testschema CASCADE;
+ALTER TABLESPACE testspace_renamed MOVE ALL TO pg_default;
+
+-- Should show notice that nothing was done
+ALTER TABLESPACE testspace_renamed MOVE ALL TO pg_default;
-- Should succeed
DROP TABLESPACE testspace_renamed;
+DROP SCHEMA testschema CASCADE;
+
DROP ROLE tablespace_testuser1;
DROP ROLE tablespace_testuser2;
ERROR: permission denied for tablespace testspace
\c -
ALTER TABLESPACE testspace RENAME TO testspace_renamed;
+ALTER TABLESPACE testspace_renamed MOVE ALL TO pg_default;
+-- Should show notice that nothing was done
+ALTER TABLESPACE testspace_renamed MOVE ALL TO pg_default;
+NOTICE: no matching relations in tablespace "testspace_renamed" found
+-- Should succeed
+DROP TABLESPACE testspace_renamed;
DROP SCHEMA testschema CASCADE;
NOTICE: drop cascades to 4 other objects
DETAIL: drop cascades to table testschema.foo
drop cascades to table testschema.asselect
drop cascades to table testschema.asexecute
drop cascades to table testschema.atable
--- Should succeed
-DROP TABLESPACE testspace_renamed;
DROP ROLE tablespace_testuser1;
DROP ROLE tablespace_testuser2;
AlterTSDictionaryStmt
AlterTableCmd
AlterTableSpaceOptionsStmt
+AlterTableSpaceMoveStmt
AlterTableStmt
AlterTableType
AlterUserMappingStmt