ALTER SCHEMA
Changes one or more schemas in one of the following ways:
-
Enable or disable inheritance of schema privileges by tables created in the schemas.
-
Reassign schema ownership to another user.
-
Change schema disk quota.
-
Rename one or more schemas.
Syntax
ALTER SCHEMA [database.]schema
DEFAULT {INCLUDE | EXCLUDE} SCHEMA PRIVILEGES
| OWNER TO user-name [CASCADE]
| DISK_QUOTA { value | SET NULL }
You can rename more than one schema in a single operation:
ALTER SCHEMA [database.]schema[,...] RENAME TO new-schema-name[,...]
Parameters
database
- Name of the database containing the schema. If specified, it must be the current database.
schema
- Name of the schema to modify.
DEFAULT {INCLUDE | EXCLUDE} SCHEMA PRIVILEGES
Specifies whether to enable or disable default inheritance of privileges for new tables in the specified schema:
-
EXCLUDE SCHEMA PRIVILEGES
(default): Disables inheritance of schema privileges. -
INCLUDE SCHEMA PRIVILEGES
: Specifies to grant tables in the specified schema the same privileges granted to that schema. This option has no effect on existing tables in the schema.
See also Enabling schema inheritance.
-
OWNER TO
- Reassigns schema ownership to the specified user:
OWNER TO user-name [CASCADE]
By default, ownership of objects in the reassigned schema remain unchanged. To reassign ownership of schema objects to the new schema owner, qualify the OWNER TO clause with CASCADE. For details, see Cascading Schema Ownership below.
DISK_QUOTA
- One of the following:
-
A string, an integer followed by a supported unit: K, M, G, or T. If the new value is smaller than the current usage, the operation succeeds but no further disk space can be used until usage is reduced below the new quota.
-
SET NULL to remove a quota.
For more information, see Disk quotas.
-
RENAME TO
- Renames one or more schemas:
RENAME TO new-schema-name[,...]
The following requirements apply:
-
The new schema name conforms to conventions described in Identifiers. It must also be unique among all names of sequences, tables, projections, views, models, and schemas in the database.
-
If you specify multiple schemas to rename, the source and target lists must have the same number of names.
Caution
Renaming a schema referenced by a view causes the view to fail unless another schema is created to replace it. -
Privileges
One of the following:
-
Superuser
-
Schema owner
Cascading schema ownership
By default, ALTER SCHEMA...OWNER TO does not affect ownership of objects in the target schema or the privileges granted on them. If you qualify the OWNER TO clause with CASCADE, Vertica acts as follows on objects in the target schema:
-
Transfers ownership of objects owned by the previous schema owner to the new owner.
-
Revokes all object privileges granted by the previous schema owner.
If issued by non-superusers, ALTER SCHEMA...OWNER TO CASCADE ignores all objects that belong to other users, and returns with notices on the objects that it cannot change. For example:
-
Schema
ms
is owned by usermayday
, and contains two tables:ms.t1
owned by mayday, andms.t2
owned by userjoe
:=> \dt List of tables Schema | Name | Kind | Owner | Comment ----------------+-----------------------+-------+---------+--------- ms | t1 | table | mayday | ms | t2 | table | joe |
-
User
mayday
transfers ownership of schemams
to userdbadmin
, using CASCADE. On return, ALTER SCHEMA reports that it cannot transfer ownership of tablems.t2
and its projections, which are owned by userjoe
:=> \c - mayday You are now connected as user "mayday". => ALTER SCHEMA ms OWNER TO dbadmin CASCADE; NOTICE 3583: Insufficient privileges on ms.t2 NOTICE 3583: Insufficient privileges on ms.t2_b0 NOTICE 3583: Insufficient privileges on ms.t2_b1 ALTER SCHEMA => \c You are now connected as user "dbadmin". => \dt List of tables Schema | Name | Kind | Owner | Comment ----------------+-----------------------+-------+---------+--------- ms | t1 | table | dbadmin | ms | t2 | table | joe |
-
User
dbadmin
transfers ownership of schemams
to userpat
, again using CASCADE. This time, becausedbadmin
is a superuser, ALTER SCHEMA transfers ownership of allms
tables to userpat
=> ALTER SCHEMA ms OWNER TO pat CASCADE; ALTER SCHEMA => \dt List of tables Schema | Name | Kind | Owner | Comment ----------------+-----------------------+-------+---------+--------- ms | t1 | table | pat | ms | t2 | table | pat |
Swapping schemas
Renaming schemas is useful for swapping schemas without actually moving data. To facilitate the swap, enter a non-existent, temporary placeholder schema. For example, the following ALTER SCHEMA
statement uses the temporary schema temps
to facilitate swapping schema S1 with schema S2. In this example, S1
is renamed to temps
. Then S2
is renamed to S1
. Finally, temps
is renamed to S2
.
=> ALTER SCHEMA S1, S2, temps RENAME TO temps, S1, S2;
Examples
The following example renames schemas S1
and S2
to S3
and S4
, respectively:
=> ALTER SCHEMA S1, S2 RENAME TO S3, S4;
This example sets the default behavior for new table t2
to automatically inherit the schema's privileges:
=> ALTER SCHEMA s1 DEFAULT INCLUDE SCHEMA PRIVILEGES;
=> CREATE TABLE s1.t2 (i, int);
This example sets the default for new tables to not automatically inherit privileges from the schema:
=> ALTER SCHEMA s1 DEFAULT EXCLUDE SCHEMA PRIVILEGES;