Help Center/ GaussDB(DWS)/ Getting Started/ Database Quick Start/ Creating and Managing Schemas
Updated on 2023-11-14 GMT+08:00

Creating and Managing Schemas

Background

Based on schema management, multiple users can use the same database without conflicts. Database objects can be organized as manageable logical groups. In addition, third-party applications can be added to the same schema without causing conflicts. Schema management involves creating a schema, using a schema, deleting a schema, setting a search path for a schema, and setting schema permissions.

Important Notes

  • The database cluster has one or more named databases. Users and user groups are shared within a cluster, but their data is exclusive. Any user who has connected to a server can only access the database that is specified in the connection request.
  • A database can have one or more schemas, and a schema can contain tables and other data objects, such as data types, functions, and operators. One object name can be used in different schemas. For example, both schema1 and schema2 can have a table named mytable.
  • Different from databases, schemas are not isolated. You can access the objects in a schema of the connected database based on your schema permissions. To manage schema permissions, you need to have a good understanding of the database permissions.
  • A schema named with the PG_ prefix cannot be created because this type of schema is reserved for the database system.
  • If a user is created, a schema named after the user will also be created in the current database.
  • To reference a table that is not modified with a schema name, the system uses search_path to find the schema that the table belongs to. pg_temp and pg_catalog are always the first two schemas to be searched no matter whether or how they are specified in search_path. search_path is a schema name list, and the first table detected in it is the target table. If no target table is found, an error will be reported. (If a table exists but the schema it belongs to is not listed in search_path, the search fails as well.) The first schema in search_path is called current schema. This schema is the first one to be searched. If no schema name is declared, newly created database objects are saved in this schema by default.
  • Each database has a pg_catalog schema, which contains system catalogs and all built-in data types, functions, and operators. pg_catalog is a part of the search path and has the second highest search priority. It is searched after the schema of temporary tables and before other schemas specified in search_path. This search order ensures that database built-in objects can be found. To use a custom object that has the same name as a built-in object, you can specify the schema of the custom object.

Procedure

  • Create a schema.
    • Run the following command to create a schema:
      1
      CREATE SCHEMA myschema;
      

      If the following information is displayed, the schema named myschema has been successfully created:

      1
      CREATE SCHEMA
      

      To create or access an object in the schema, the object name in the command should be composed of the schema name and the object name, which are separated by a dot (.), for example, myschema.table.

    • Run the following command to create a schema and specify the owner:
      1
      CREATE SCHEMA myschema AUTHORIZATION dbadmin;
      

      If the following information is displayed, the myschema schema that belongs to dbadmin has been created successfully:

      1
      CREATE SCHEMA
      
  • Use a schema.

    If you want to create or access an object in a specified schema, the object name must contain the schema name. To be specific, the name consists of a schema name and an object name, which are separated by a dot (.).

    • Run the following command to create table mytable in myschema:
      1
      CREATE TABLE myschema.mytable(id int, name varchar(20));
      

      To specify the location of an object, the object name must contain the schema name.

    • Run the following command to query all data of table mytable in myschema:
      1
      2
      3
      4
      SELECT * FROM myschema.mytable;
      id | name 
      ----+------
      (0 rows)
      
  • View search_path of a schema.

    You can set search_path to specify the sequence of schemas in which objects are searched. The first schema listed in search_path will become the default schema. If no schema is specified during object creation, the object will be created in the default schema.

    • Run the following command to view search_path:
      1
      2
      3
      4
      5
      SHOW SEARCH_PATH;
       search_path
      ----------------
       "$user",public
      (1 row)
      
    • Run the following command to set search_path to myschema and public (myschema is searched first):
      1
      2
      SET SEARCH_PATH TO myschema, public;
      SET
      
  • Set permissions for a schema.

    By default, a user can only access database objects in its own schema. Only after a user is granted with the usage permission on a schema by the schema owner, the user can access the objects in the schema.

    By granting the CREATE permission for a schema to a user, the user can create objects in this schema.

    • Run the following command to view the current schema:
      1
      2
      3
      4
      5
      SELECT current_schema();
       current_schema 
      ----------------
       myschema
      (1 row)
      
    • Run the following commands to create user jack and grant the usage permission on myschema to the user:
      1
      2
      CREATE USER jack IDENTIFIED BY 'password';
      GRANT USAGE ON schema myschema TO jack;
      
    • Run the following command to revoke the USAGE permission for myschema from jack:
      1
      REVOKE USAGE ON schema myschema FROM jack;
      
  • Delete a schema.
    • If a schema is empty, that is, it contains no database object, you can execute the DROP SCHEMA statement to delete it. For example, run the following command to delete an empty schema named nullschema:
      1
      DROP SCHEMA IF EXISTS nullschema;
      
    • To delete a schema that is not null, use the keyword CASCADE to delete it and all its objects. For example, run the following command to delete myschema and all objects in it:
      1
      DROP SCHEMA myschema CASCADE;
      
    • Delete user jack.
      1
      DROP USER jack;