Add ALTER TABLESPACE ... MOVE command
authorStephen Frost <[email protected]>
Sat, 18 Jan 2014 23:56:40 +0000 (18:56 -0500)
committerStephen Frost <[email protected]>
Sat, 18 Jan 2014 23:56:40 +0000 (18:56 -0500)
This adds a 'MOVE' sub-command to ALTER TABLESPACE which allows moving sets of
objects from one tablespace to another.  This can be extremely handy and avoids
a lot of error-prone scripting.  ALTER TABLESPACE ... MOVE will only move
objects the user owns, will notify the user if no objects were found, and can
be used to move ALL objects or specific types of objects (TABLES, INDEXES, or
MATERIALIZED VIEWS).

13 files changed:
doc/src/sgml/ref/alter_tablespace.sgml
src/backend/commands/tablespace.c
src/backend/nodes/copyfuncs.c
src/backend/nodes/equalfuncs.c
src/backend/parser/gram.y
src/backend/tcop/utility.c
src/include/commands/tablespace.h
src/include/nodes/nodes.h
src/include/nodes/parsenodes.h
src/include/parser/kwlist.h
src/test/regress/input/tablespace.source
src/test/regress/output/tablespace.source
src/tools/pgindent/typedefs.list

index 7d3ee2ce813c5d5b39dc60d347cb9441d809d710..0dfa4652fd71684564c1090c9b09f06cd7c7ef6e 100644 (file)
@@ -12,7 +12,7 @@ PostgreSQL documentation
 
  <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">
@@ -25,6 +25,7 @@ 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 } TO <replaceable>new_tablespace</replaceable> [ NOWAIT ]
 </synopsis>
  </refsynopsisdiv>
 
@@ -32,15 +33,34 @@ ALTER TABLESPACE <replaceable>name</replaceable> RESET ( <replaceable class="PAR
   <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>
 
@@ -94,6 +114,30 @@ ALTER TABLESPACE <replaceable>name</replaceable> RESET ( <replaceable class="PAR
      </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>
 
@@ -111,6 +155,13 @@ 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 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>
 
index 07f5221088fea7b7d74b5533cdb9704f6c974939..cb2499af7d2a8fbadce10b18ccc49233fe5e4f97 100644 (file)
 #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"
@@ -955,6 +960,172 @@ AlterTableSpaceOptions(AlterTableSpaceOptionsStmt *stmt)
        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'.
  */
index fb4ce2cf21fdf2acde20584ea3c03625c53b1405..19e5f0495a87f8a8c1d8d09da356d6915d2b4194 100644 (file)
@@ -3397,6 +3397,18 @@ _copyAlterTableSpaceOptionsStmt(const AlterTableSpaceOptionsStmt *from)
        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)
 {
@@ -4408,6 +4420,9 @@ copyObject(const void *from)
                case T_AlterTableSpaceOptionsStmt:
                        retval = _copyAlterTableSpaceOptionsStmt(from);
                        break;
+               case T_AlterTableSpaceMoveStmt:
+                       retval = _copyAlterTableSpaceMoveStmt(from);
+                       break;
                case T_CreateExtensionStmt:
                        retval = _copyCreateExtensionStmt(from);
                        break;
index ccf726741d8673b00fb1f5e13ee3289ae2bcb41a..55c548d5e49fa4517447ba47f6b34797c769d30c 100644 (file)
@@ -1634,6 +1634,17 @@ _equalAlterTableSpaceOptionsStmt(const AlterTableSpaceOptionsStmt *a,
        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)
 {
@@ -2877,6 +2888,9 @@ equal(const void *a, const void *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;
index f0b95071d5e758ded8b757daf5b9c08ddb861fee..1b63d415318fd29deb6b8257e6e6180f3c4744bb 100644 (file)
@@ -601,7 +601,7 @@ static Node *makeRecursiveViewSelect(char *relname, List *aliases, Node *query);
        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
 
@@ -7319,6 +7319,49 @@ RenameStmt: ALTER AGGREGATE func_name aggr_args RENAME TO name
                                        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 =
@@ -12887,6 +12930,7 @@ unreserved_keyword:
                        | VARYING
                        | VERSION_P
                        | VIEW
+                       | VIEWS
                        | VOLATILE
                        | WHITESPACE_P
                        | WITHIN
index 36cf72d05fb4290a4b65e4c6e07ec2904a01777e..f4d25bd1edd1e0065b6ad165925f4b0f029d14c9 100644 (file)
@@ -243,6 +243,7 @@ check_xact_readonly(Node *parsetree)
                case T_AlterUserMappingStmt:
                case T_DropUserMappingStmt:
                case T_AlterTableSpaceOptionsStmt:
+               case T_AlterTableSpaceMoveStmt:
                case T_CreateForeignTableStmt:
                case T_SecLabelStmt:
                        PreventCommandIfReadOnly(CreateCommandTag(parsetree));
@@ -548,6 +549,11 @@ standard_ProcessUtility(Node *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;
@@ -1822,6 +1828,10 @@ CreateCommandTag(Node *parsetree)
                        tag = "ALTER TABLESPACE";
                        break;
 
+               case T_AlterTableSpaceMoveStmt:
+                       tag = "ALTER TABLESPACE";
+                       break;
+
                case T_CreateExtensionStmt:
                        tag = "CREATE EXTENSION";
                        break;
@@ -2514,6 +2524,10 @@ GetCommandLogLevel(Node *parsetree)
                        lev = LOGSTMT_DDL;
                        break;
 
+               case T_AlterTableSpaceMoveStmt:
+                       lev = LOGSTMT_DDL;
+                       break;
+
                case T_CreateExtensionStmt:
                case T_AlterExtensionStmt:
                case T_AlterExtensionContentsStmt:
index c7af55917d77f15f75ede7254b237a150641aceb..1603f677a7de23b68d7e0ac6da7eeca0617a2d2f 100644 (file)
@@ -43,6 +43,7 @@ extern Oid    CreateTableSpace(CreateTableSpaceStmt *stmt);
 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);
 
index ae12c0de038a6aec927020c2f1b2feb07a51f875..dfcc01344eaf9c7ee75154b429932c89f79f213a 100644 (file)
@@ -354,6 +354,7 @@ typedef enum NodeTag
        T_AlterUserMappingStmt,
        T_DropUserMappingStmt,
        T_AlterTableSpaceOptionsStmt,
+       T_AlterTableSpaceMoveStmt,
        T_SecLabelStmt,
        T_CreateForeignTableStmt,
        T_CreateExtensionStmt,
index 9a3a5d76cc2f52a36e16de34b6d3729d12157af7..f86edc61c3adf8986f17fd65b3d2b0711b199a75 100644 (file)
@@ -1686,6 +1686,16 @@ typedef struct AlterTableSpaceOptionsStmt
        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
  * ----------------------
index 41ec2696b05d5b4e1ae0607196892c4b81768e55..61fae22f0a0e1b396660dd52ca33df2d2df86931 100644 (file)
@@ -406,6 +406,7 @@ PG_KEYWORD("varying", VARYING, UNRESERVED_KEYWORD)
 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)
index 4f17b09fa94883864d3a1735e2db03436a3bf161..8ee7efa5f816bdac99a5c20d80b55c1b350b0fb8 100644 (file)
@@ -66,10 +66,15 @@ CREATE TABLE tablespace_table (i int) TABLESPACE testspace; -- fail
 
 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;
index 2868169c6ceecc09fca5ed046760af743b1deb06..cb5d139101cb3fb206446700d9d5deb4fcc3d4a1 100644 (file)
@@ -80,13 +80,17 @@ CREATE TABLE tablespace_table (i int) TABLESPACE testspace; -- fail
 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;
index e3058be6a5a6923b1d51fe58e0817be71e237e64..1f735b70b7a55d37c0fadca456d6bb7567b92ca0 100644 (file)
@@ -76,6 +76,7 @@ AlterTSConfigurationStmt
 AlterTSDictionaryStmt
 AlterTableCmd
 AlterTableSpaceOptionsStmt
+AlterTableSpaceMoveStmt
 AlterTableStmt
 AlterTableType
 AlterUserMappingStmt