Updated on 2024-05-07 GMT+08:00

CREATE SCHEMA

Description

Creates a schema.

Named objects are accessed either by "qualifying" their names with the schema name as a prefix, or by setting a search path that includes the desired schema. When creating named objects, you can also use the schema name as a prefix.

Optionally, CREATE SCHEMA can include sub-commands to create objects within the new schema. The sub-commands are treated essentially the same as separate commands issued after creating the schema. If the AUTHORIZATION clause is used, all the created objects are owned by this user.

Precautions

  • Only a user with the CREATE permission on the current database can perform this operation.
  • The owner of an object created by a system administrator in a schema with the same name as a common user is the common user, not the system administrator.

Syntax

  • Create a schema based on a specified name.
    CREATE SCHEMA schema_name 
        [ AUTHORIZATION user_name ]  [ schema_element [ ... ] ];
  • Create a schema based on a username.
    CREATE SCHEMA AUTHORIZATION user_name [ schema_element [ ... ] ];
  • Create a schema and specify the default character set and collation.
    CREATE SCHEMA schema_name 
        [ [DEFAULT] CHARACTER SET | CHARSET [ = ] default_charset ] [ [DEFAULT] COLLATE [ = ] default_collation ];

Parameters

  • schema_name

    Specifies the schema name.

    • The schema name must be unique in the current database.
    • The schema name cannot be the same as the initial username of the current database.
    • The schema name cannot start with pg_.
    • The schema name cannot start with gs_role_.

    Value range: a string. It must comply with the naming convention.

  • AUTHORIZATION user_name

    Specifies the owner of a schema. If schema_name is not specified, user_name will be used as the schema name. In this case, user_name can only be a role name.

    Value range: an existing username or role name

  • schema_element

    Specifies an SQL statement defining an object to be created within the schema. Currently, only the CREATE TABLE, CREATE VIEW, CREATE INDEX, CREATE PARTITION, CREATE SEQUENCE, CREATE TRIGGER, and GRANT clauses are supported.

    Objects created by sub-commands are owned by the user specified by AUTHORIZATION.

  • default_charset

    This syntax is supported only when sql_compatibility is set to 'B'. Specifies the default character set of a schema. If you specify a character set separately, the default collation of the schema is set to the default collation of the specified character set.

  • default_collation

    This syntax is supported only when sql_compatibility is set to 'B'. Specifies the default collation of a schema. If you specify a collation separately, the default character set of the schema is set to the character set corresponding to the specified collation.

    For details about the supported collation, see Table 1 Character sets and collation supported in mode B (sql_compatibility = 'B').

If objects in the schema on the current search path are with the same name, specify the schemas for different objects. You can run SHOW SEARCH_PATH to check the schemas on the current search path.

Examples

-- Create the role1 role.
gaussdb=# CREATE ROLE role1 IDENTIFIED BY '********';

-- Create a schema named role1 for the role1 role. The owner of the films and winners tables created by the clause is role1.
gaussdb=# CREATE SCHEMA AUTHORIZATION role1
     CREATE TABLE films (title text, release date, awards text[])      
     CREATE VIEW winners AS         
     SELECT title, release FROM films WHERE awards IS NOT NULL;

-- Create a schema ds and set the default character set of the schema to utf8mb4 and the default collation to utf8mb4_bin.
gaussdb=# CREATE SCHEMA ds CHARACTER SET utf8mb4 COLLATE utf8mb4_bin;

-- Delete the schema.
gaussdb=# DROP SCHEMA role1 CASCADE;
-- Delete the user.
gaussdb=# DROP USER role1 CASCADE;

Helpful Links

ALTER SCHEMA and DROP SCHEMA