CREATE SCHEMA
Defines a schema.
Syntax
CREATE SCHEMA [ IF NOT EXISTS ] [database.]schema
[ AUTHORIZATION username]
[ DEFAULT { INCLUDE | EXCLUDE } [ SCHEMA ] PRIVILEGES ]
Parameters
IF NOT EXISTS
If an object with the same name exists, do not create it and proceed. If you omit this option and the object exists, Vertica generates a ROLLBACK error message. In both cases, the object is not created if it already exists.
The
IF NOT EXISTS
clause is useful for SQL scripts where you want to create an object if it does not already exist.For related information, see ON_ERROR_STOP.
[
database
.]
schema
- Identifies the schema to create, where
schema
conforms to conventions described in Identifiers. The following naming requirements also apply:-
The name must be unique among all other schema names in the database.
-
It must comply with keyword restrictions.
-
It cannot begin with
v_
; this prefix is reserved for Vertica system tables. -
If you specify a database, it must be the current database.
-
AUTHORIZATION
username
- Valid only for superusers, assigns ownership of the schema to another user. By default, the user who creates a schema is also assigned ownership.
After you create a schema, you can reassign ownership to another user with
ALTER SCHEMA
. 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.
If you omit
INCLUDE PRIVILEGES
, you must explicitly grant schema privileges on the desired tables.For more information see Enabling schema inheritance.
-
Privileges
-
Superuser
Supported sub-statements
CREATE SCHEMA
can include one or more sub-statements—for example, to create tables or projections within the new schema. Supported sub-statements include:
CREATE SCHEMA
statement and all sub-statements are treated as a single transaction. If any statement fails, Vertica rolls back the entire transaction. The owner of the new schema is assigned ownership of all objects that are created within this transaction.
For example, the following CREATE SCHEMA
statement also grants privileges on the new schema, and creates a table and view of that table:
=> \c - Joan
You are now connected as user "Joan".
=> CREATE SCHEMA s1
GRANT USAGE, CREATE ON SCHEMA s1 TO public
CREATE TABLE s1.t1 (a varchar)
CREATE VIEW s1.t1v AS SELECT * FROM s1.t1;
CREATE SCHEMA
=> \dtv s1.*
List of tables
Schema | Name | Kind | Owner | Comment
--------+------+-------+-------+---------
s1 | t1 | table | Joan |
s1 | t1v | view | Joan |
(2 rows)
Examples
Create schema s1
:
=> CREATE SCHEMA s1;
Create schema s2
if it does not already exist:
=> CREATE SCHEMA IF NOT EXISTS s2;
If the schema already exists, Vertica returns a rollback message:
=> CREATE SCHEMA IF NOT EXISTS s2;
NOTICE 4214: Object "s2" already exists; nothing was done
Create table t1
in schema s1
, then grant users Fred
and Aniket
access to all existing tables and all privileges on table t1
:
=> CREATE TABLE s1.t1 (c INT);
CREATE TABLE
=> GRANT USAGE ON SCHEMA s1 TO Fred, Aniket;
GRANT PRIVILEGE
=> GRANT ALL PRIVILEGES ON TABLE s1.t1 TO Fred, Aniket;
GRANT PRIVILEGE
Enable inheritance on new schema s3
so all tables created in it automatically inherit its privileges. In this case, new table s3.t2
inherits USAGE, CREATE, and SELECT privileges, which are automatically granted to all database users:
=> CREATE SCHEMA s3 DEFAULT INCLUDE SCHEMA PRIVILEGES; CREATE SCHEMA => GRANT USAGE, CREATE, SELECT, INSERT ON SCHEMA S3 TO PUBLIC; GRANT PRIVILEGE => CREATE TABLE s3.t2(i int); WARNING 6978: Table "t2" will include privileges from schema "s3" CREATE TABLE