• Data Warehouse Service

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

CREATE ROLE

Function

  • CREATE ROLE adds a role to a database. The role does not have the login permission.
  • A role is an entity that has database objects and permissions. In different environments, a role can be considered as a user, a group, or both.
  • Only the user who has the CREATE ROLE permission or the system administrator is allowed to create roles.

Precautions

None

Syntax

CREATE ROLE role_name [ [ WITH ] option [ ... ] ] [ ENCRYPTED | UNENCRYPTED ] { PASSWORD | IDENTIFIED BY } { 'password' | DISABLE };
The syntax of role information configuration clause option is as follows:
{SYSADMIN | NOSYSADMIN}
    | {AUDITADMIN | NOAUDITADMIN}
    | {CREATEDB | NOCREATEDB}
    | {USEFT | NOUSEFT}
    | {CREATEROLE | NOCREATEROLE}
    | {INHERIT | NOINHERIT}
    | {LOGIN | NOLOGIN}
    | {REPLICATION | NOREPLICATION}
    | {INDEPENDENT | NOINDEPENDENT}
    | {VCADMIN | NOVCADMIN}
    | CONNECTION LIMIT connlimit
    | VALID BEGIN 'timestamp'
    | VALID UNTIL 'timestamp'
    | RESOURCE POOL 'respool'
    | USER GROUP 'groupuser'
    | PERM SPACE 'spacelimit'
    | NODE GROUP logic_cluster_name
    | IN ROLE role_name [, ...]
    | IN GROUP role_name [, ...]
    | ROLE role_name [, ...]
    | ADMIN rol e_name [, ...]
    | USER role_name [, ...]
    | SYSID uid
    | DEFAULT TABLESPACE tablespace_name
    | PROFILE DEFAULT
    | PROFILE profile_name
    | PGUSER

Parameter Description

  • role_name

    Indicates the name of a role.

    Value range: A string. It must comply with the naming convention rule. and can contain a maximum of 63 characters.

  • password

    Specifies the login password.

    The password must:

    • Contain at least eight characters. This is the default length.
    • Differ from the user name or the user name spelled backward.
    • Contain at least three of the following: uppercase characters (A to Z), lowercase characters (a to z), digits (0 to 9), and other characters (limited to ~!@#$%^&*()-_=+\|[{}];:,<.>/?).

    Value range: A string.

  • DISABLE

    By default, you can change your password unless it is disabled. To disable the password of a user, use this parameter. After the password of a user is disabled, the password will be deleted from the system. The user can connect to the database only through external authentication, for example, IAM authentication. Only administrators can enable or disable a password. Common users cannot disable the password of an initial user. To enable a password, run ALTER USER and specify the password.

  • ENCRYPTED | UNENCRYPTED

    These key words control whether the password is stored encrypted in the system catalogs. (If neither is specified, the default behavior is determined by the configuration parameter password_encryption.) According to product security requirements, the password must be stored encrypted. Therefore, UNENCRYPTED is forbidden in DWS. If the presented password string is already in SHA256-encrypted format, then it is stored encrypted as-is, regardless of whether ENCRYPTED or UNENCRYPTED is specified (since the system cannot decrypt the specified encrypted password string). This allows reloading of encrypted passwords during dump/restore.

  • SYSADMIN | NOSYSADMIN

    Determines whether a new role is a system administrator. Roles having the SYSADMIN attribute have the highest permission.

    Value range: If not specified, NOSYSADMIN is the default.

  • AUDITADMIN | NOAUDITADMIN

    Determines whether a role has the audit and management attributes.

    If not specified, NOAUDITADMIN is the default.

  • CREATEDB | NOCREATEDB

    Defines a role's ability to create databases.

    A new role does not have the permission to create databases.

    Value range: If not specified, NOCREATEDB is the default.

  • USEFT | NOUSEFT

    Determines whether a new role can perform operations on foreign tables, such as creating, deleting, modifying, and reading/witting foreign tables.

    A new role does not have permissions for these operations.

    The default value is NOUSEFT.

  • CREATEROLE | NOCREATEROLE

    Determines whether a role will be permitted to create new roles (that is, execute CREATE ROLE). A role with the CREATEROLE permission can also modify and delete other roles.

    Value range: If not specified, NOCREATEROLE is the default.

  • INHERIT | NOINHERIT

    Determines whether a role "inherits" the permissions of roles it is a member of. You are not advised to execute them.

  • LOGIN | NOLOGIN

    Determines whether a role is allowed to log in to a database. A role having the LOGIN attribute can be thought of as a user.

    Value range: If not specified, NOLOGIN is the default.

  • REPLICATION | NOREPLICATION

    Determines whether a role is allowed to initiate streaming replication or put the system in and out of backup mode. A role having the REPLICATION attribute is a highly privileged role, and should only be used on roles used for replication.

    If not specified, NOREPLICATION is the default.

  • INDEPENDENT | NOINDEPENDENT

    Defines private, independent roles. For a role with the INDEPENDENT attribute, administrators' rights to control and access this role are separated. Specific rules are as follows:

    • Administrators have no rights to add, delete, query, modify, copy, or authorize the corresponding table objects without the authorization from the INDEPENDENT role.
    • Administrators have no rights to modify the inheritance relationship of the INDEPENDENT role without the authorization from this role.
    • Administrators have no rights to modify the owner of the table objects for the INDEPENDENT role.
    • Administrators have no rights to delete the INDEPENDENT attribute of the INDEPENDENT role.
    • Administrators have no rights to change the database password of the INDEPENDENT role. The INDEPENDENT role must manage its own password, which cannot be reset if lost.
    • The SYSADMIN attribute of a user cannot be changed to the INDEPENDENT attribute.
  • VCADMIN | NOVCADMIN

    Defines the role of a logical cluster administrator. A logical cluster administrator has the following more permissions than common users:

    • Create, modify, and delete resource pools in the associated logical cluster.
    • Grant the access permission for the associated logical cluster to other users or roles, or reclaim the access permission from those users or roles.
  • CONNECTION LIMIT

    Indicates how many concurrent connections the role can make.

    Value range: Integer, >=-1. The default value is -1, which means unlimited.

  • VALID BEGIN

    Sets a date and time when the role's password becomes valid. If this clause is omitted, the password will be valid for all time.

  • VALID UNTIL

    Sets a date and time after which the role's password is no longer valid. If this clause is omitted, the password will be valid for all time.

  • RESOURCE POOL

    Sets the name of resource pool used by the role, and the name belongs to the system catalog: pg_resource_pool.

  • USER GROUP 'groupuser'

    Creates a sub-user.

  • PERM SPACE

    Sets the space used for users.

  • NODE GROUP

    Specifies the name of the logical cluster associated with a user. If the name contains uppercase characters or special characters, enclose the name with double quotation marks.

  • IN ROLE

    Lists one or more existing roles whose permissions will be inherited by a new role. You are not advised to execute them.

  • IN GROUP

    Indicates an obsolete spelling of IN ROLE. You are not advised to execute them.

  • ROLE

    Lists one or more existing roles which are automatically added as members of the new role.

  • ADMIN

    Is similar to ROLE. However, the roles after ADMIN can grant rights of new roles to other roles.

  • USER

    Indicates an obsolete spelling of the ROLE clause.

  • SYSID

    The SYSID clause is ignored.

  • DEFAULT TABLESPACE

    The DEFAULT TABLESPACE clause is ignored.

  • PROFILE

    The PROFILE clause is ignored.

  • PGUSER

    This attribute is used to be compatible with open-source Postgres communication. An open-source Postgres client interface (Postgres 9.2.19 is recommended) can use a database user having this attribute to connect to the database.

    This attribute only ensures compatibility with the connection process. Incompatibility caused by kernel differences between this product and Postgres cannot be solved using this attribute.

    Users having the PGUSER attribute are authenticated in a way different from other users. Error information reported by the open-source client may cause the attribute to be enumerated. Therefore, you are advised to use a client of this product. For example:

    # normaluser is a user that does not have the PGUSER attribute. psql is the Postgres client tool.
    pg@MPPDB04:~> psql -d postgres -p 8000 -h 10.11.12.13 -U normaluser
    psql: authentication method 10 not supported
    
    # pguser is a user having the PGUSER attribute.
    pg@MPPDB04:~> psql -d postgres -p 8000 -h 10.11.12.13 -U pguser
    Password for user pguser:

Examples

-- Create a role manager whose password is Bigdata123@:
CREATE ROLE manager IDENTIFIED BY 'Bigdata123@';

-- Create a role with a validity from January 1, 2015 to January 1, 2026:
CREATE ROLE miriam WITH LOGIN PASSWORD 'Bigdata123@' VALID BEGIN '2015-01-01' VALID UNTIL '2026-01-01';

-- Alter the password of role manager to abcd@123:
ALTER ROLE manager IDENTIFIED BY 'abcd@123' REPLACE 'Bigdata123@';

-- Alter role manager to the system administrator:
ALTER ROLE manager SYSADMIN;

-- Delete the manager role:
DROP ROLE manager;

-- Delete the role miriam:
DROP ROLE miriam;