• Data Warehouse Service

dws
  1. Help Center
  2. Data Warehouse Service
  3. Developer Guide
  4. SQL Reference
  5. SQL Syntax
  6. GRANT

GRANT

Function

GRANT grants rights to roles and users.

GRANT is used in the following scenarios:

  • Granting system rights to roles or users

    System rights are also called user attributes, including SYSADMIN, CREATEDB, CREATEROLE, AUDITADMIN, and LOGIN.

    They can be specified only by the CREATE ROLE or ALTER ROLE syntax. The SYSADMIN permissions can be granted and revoked using GRANT ALL PRIVILEGE and REVOKE ALL PRIVILEGE, respectively. System rights cannot be inherited by a user from a role, and cannot be granted using PUBLIC.

  • Granting database object rights to roles or users

    Grant permissions related to database objects (tables, views, specified columns, databases, functions, and schemas) to specified roles or users.

    GRANT grants specified database object rights to one or more roles. These rights are added to those already granted, if any.

  • Granting a role's or user's rights to other roles or users

    Grant a role's or user's rights to one or more roles or users. In this case, every role or user can be regarded as a set of one or more database rights.

    If WITH ADMIN OPTION is specified, the member can in turn grant rights in the role to others, and revoke rights in the role as well. If a role or user granted with certain rights is changed or revoked, the rights inherited from the role or user also change.

    A database administrator can grant rights to and revoke them from any role or user. Roles having CREATEROLE permission can grant or revoke membership in any role that is not an administrator.

Precautions

To isolate permissions, DWS disables the WITH GRANT OPTION and TO PUBLIC syntax.

Syntax

  • Grant the table or view access permission to a specified role or user. GRANT to a table partition will cause alarms.
    GRANT { { SELECT | INSERT | UPDATE | DELETE | TRUNCATE | REFERENCES } [, ...] 
          | ALL [ PRIVILEGES ] }
        ON { [ TABLE ] table_name [, ...]
           | ALL TABLES IN SCHEMA schema_name [, ...] }
        TO { [ GROUP ] role_name | PUBLIC } [, ...] 
        [ WITH GRANT OPTION ];
  • Grant the column access permission to a specified role or user.
    GRANT { {{ SELECT | INSERT | UPDATE | REFERENCES } ( column_name [, ...] )} [, ...] 
          | ALL [ PRIVILEGES ] ( column_name [, ...] ) }
        ON [ TABLE ] table_name [, ...]
        TO { [ GROUP ] role_name | PUBLIC } [, ...]
        [ WITH GRANT OPTION ];
  • Grant the database access permission to a specified role or user.
    GRANT { { CREATE | CONNECT | TEMPORARY | TEMP } [, ...]
          | ALL [ PRIVILEGES ] }
        ON DATABASE database_name [, ...]
        TO { [ GROUP ] role_name | PUBLIC } [, ...]
        [ WITH GRANT OPTION ];
  • Grant the domain access permission to a specified role or user.
    GRANT { USAGE | ALL [ PRIVILEGES ] }
        ON DOMAIN domain_name [, ...]
        TO { [ GROUP ] role_name | PUBLIC } [, ...]
        [ WITH GRANT OPTION ];
    NOTE:

    The current version does not support granting the domain access permission.

  • Grant the external data source access permission to a specified role or user.
    GRANT { USAGE | ALL [ PRIVILEGES ] }
        ON FOREIGN DATA WRAPPER fdw_name [, ...]
        TO { [ GROUP ] role_name | PUBLIC } [, ...]
        [ WITH GRANT OPTION ];
  • Grant the external server access permission to a specified role or user.
    GRANT { USAGE | ALL [ PRIVILEGES ] }
        ON FOREIGN SERVER server_name [, ...]
        TO { [ GROUP ] role_name | PUBLIC } [, ...]
        [ WITH GRANT OPTION ];
  • Grant the function access permission to a specified role or user.
    GRANT { EXECUTE | ALL [ PRIVILEGES ] }
        ON { FUNCTION {function_name ( [ {[ argmode ] [ arg_name ] arg_type} [, ...] ] )} [, ...]
           | ALL FUNCTIONS IN SCHEMA schema_name [, ...] }
        TO { [ GROUP ] role_name | PUBLIC } [, ...]
        [ WITH GRANT OPTION ];
  • Grant the procedural language access permission to a specified role or user.
    GRANT { USAGE | ALL [ PRIVILEGES ] }
        ON LANGUAGE lang_name [, ...]
        TO { [ GROUP ] role_name | PUBLIC } [, ...]
        [ WITH GRANT OPTION ];
    NOTE:

    The current version does not support granting the procedural language access permission.

  • Grant the large object access permission to a specified role or user.
    GRANT { { SELECT | UPDATE } [, ...] | ALL [ PRIVILEGES ] }
        ON LARGE OBJECT loid [, ...]
        TO { [ GROUP ] role_name | PUBLIC } [, ...]
        [ WITH GRANT OPTION ];
    NOTE:

    The current version does not support granting the large object access permission.

  • Grant the sub-cluster access permission to a specified role or user. Common users cannot grant or revoke the node-group access permission.
    GRANT { CREATE | USAGE | COMPUTE | ALL [ PRIVILEGES ] }
        ON NODE GROUP group_name [, ...]
        TO { [ GROUP ] role_name | PUBLIC } [, ...]
        [ WITH GRANT OPTION ];
  • Grant the schema access permission to a specified role or user.
    GRANT { { CREATE | USAGE } [, ...] | ALL [ PRIVILEGES ] }
        ON SCHEMA schema_name [, ...]
        TO { [ GROUP ] role_name | PUBLIC } [, ...]
        [ WITH GRANT OPTION ];

    When you grant table or view rights to other users, you also need to grant the USAGE permission for the schema that the tables and views belong to. Without this permission, the users granted with the table or view rights can only see the object names, but cannot access them.

  • Grant the type access permission to a specified role or user.
    GRANT { USAGE | ALL [ PRIVILEGES ] }
        ON TYPE type_name [, ...]
        TO { [ GROUP ] role_name | PUBLIC } [, ...]
        [ WITH GRANT OPTION ];
    NOTE:

    The current version does not support granting the type access permission.

  • Grant a role's rights to other users or roles.
    GRANT role_name [, ...]
       TO role_name [, ...]
       [ WITH ADMIN OPTION ];
  • Grant the SYSADMIN permission to a specified role.
    GRANT ALL { PRIVILEGES | PRIVILEGE }
       TO role_name;

Parameter Description

GRANT grants the following permissions:

  • SELECT

    Allows SELECT from any column, or the specific columns listed, of the specified table, view, or sequence.

  • INSERT

    Allows INSERT of a new row into the specified table.

  • UPDATE

    Allows UPDATE of any column, or the specific columns listed, of the specified table. SELECT ... FOR UPDATE and SELECT ... FOR SHARE also require this permission on at least one column, in addition to the SELECT permission.

  • DELETE

    Allows DELETE of a row from the specified table.

  • TRUNCATE

    Allows TRUNCATE on the specified table.

  • REFERENCES

    To create a foreign key constraint, it is necessary to have this permission on both the referencing and referenced columns.

  • CREATE
    • For databases, allows new schemas to be created within the database.
    • For schemas, allows new objects to be created within the schema. To rename an existing object, you must own the object and have this permission for the containing schema.
    • For sub-clusters, allows tables to be created.
  • CONNECT

    Allows the user to connect to the specified database.

  • EXECUTE

    Allows the use of the specified function and the use of any operators that are implemented on top of the function.

  • USAGE
    • For procedural languages, allows the use of the specified language for the creation of functions in that language.
    • For schemas, allows access to objects contained in the specified schema. Without this permission, it is still possible to see the object names.
    • For sequences, this permission allows the use of the nextval function.
    • For sub-clusters, allows users who can access objects contained in the specified schema to access objects in a specified sub-cluster.
  • COMPUTE

    Allows users to perform elastic computing in a sub-cluster that they have the compute permission on.

  • ALL PRIVILEGES

    Grants all of the available permissions at once.

GRANT parameters are as follows:

  • role_name

    Specifies an existing user name.

  • table_name

    Specifies an existing table name.

  • column_name

    Specifies an existing column name.

  • schema_name

    Specifies an existing schema name.

  • database_name

    Specifies an existing database name.

  • funcation_name

    Specifies an existing function name.

  • sequence_name

    Specifies an existing sequence name.

  • domain_name

    Specifies an existing domain type.

  • fdw_name

    Specifies an existing foreign data wrapper name.

  • lang_name

    Specifies an existing language name.

  • type_name

    Specifies an existing type name.

  • group_name

    Specifies an existing sub-cluster name.

  • argmode

    Specifies the parameter mode.

    Value range: a string compliant with the naming convention.

  • arg_name

    Indicates the parameter name.

    Value range: a string compliant with the naming convention.

  • arg_type

    Specifies the parameter type.

    Value range: a string compliant with the naming convention.

  • loid

    Identifier of the large object that includes this page

    Value range: a string compliant with the naming convention.

Example

Example: Grant system rights to a user or role.

Create user joe and grant the sysadmin permissions to it.

CREATE USER joe PASSWORD 'Bigdata123@';
GRANT ALL PRIVILEGES TO joe;

Afterward, user joe has the sysadmin permissions.

Example: Grant object rights to a user or role.

  1. Revoke user joe's sysadmin permissions, and grant it with the usage permission for the tpcds schema and all the permissions for the tpcds.reason table.
    REVOKE ALL PRIVILEGES FROM joe;
    GRANT USAGE ON SCHEMA tpcds TO joe;
    GRANT ALL PRIVILEGES ON tpcds.reason TO joe;

    After the granting succeeds, user joe has all the permissions for the tpcds.reason table, including addition, deletion, modification, and query permissions.

  2. Grant the query permission for r_reason_sk, r_reason_id, and r_reason_desc columns and the update permission for the r_reason_desc column in the tpcds.reason table to user joe.
    GRANT select (r_reason_sk,r_reason_id,r_reason_desc),update (r_reason_desc) ON tpcds.reason TO joe;

    After the granting succeeds, user joe immediately has the query permission for r_reason_sk and r_reason_id columns in the tpcds.reason table.

    GRANT select (r_reason_sk, r_reason_id) ON tpcds.reason TO joe;

    Grant the postgres database connection permission and schema creation permission to user joe.

    GRANT create,connect on database postgres TO joe;

    Create role tpcds_manager, grant the tpcds schema access permission and object creation permission to this role, but do not enable it to grant these permissions to others.

    CREATE ROLE tpcds_manager PASSWORD 'Bigdata123@';
    GRANT USAGE,CREATE ON SCHEMA tpcds TO tpcds_manager;
    

Example: Grant a user's or role's rights to other users or roles.

  1. Create role manager, grant user joe's rights to this role, and enable this role to grant its rights to others.
    CREATE ROLE manager PASSWORD 'Bigdata123@';
    GRANT joe TO manager WITH ADMIN OPTION;
  2. Create user senior_manager and grant manager's rights to it.
    CREATE ROLE senior_manager PASSWORD 'Bigdata123@';
    GRANT manager TO senior_manager;
  3. Revoke the rights and delete the user.
    REVOKE manager FROM joe;
    REVOKE senior_manager FROM manager;
    DROP USER manager;

Example: Revoke the granted rights and delete the roles and users.

REVOKE USAGE,CREATE ON SCHEMA tpcds FROM tpcds_manager;
DROP ROLE tpcds_manager;
DROP ROLE senior_manager;
DROP USER joe CASCADE;