ALTER ROLE
Function
ALTER ROLE changes the attributes of a role.
Precautions
None
Syntax
- Modifying the Rights of a Role
1
ALTER ROLE role_name [ [ WITH ] option [ ... ] ];
The option clause for granting rights is as follows:
1 2 3 4 5 6 7 8 9 10 11 12 13 14 15 16 17 18 19 20 21 22 23 24 25 26 27
{CREATEDB | NOCREATEDB} | {CREATEROLE | NOCREATEROLE} | {INHERIT | NOINHERIT} | {AUDITADMIN | NOAUDITADMIN} | {SYSADMIN | NOSYSADMIN} | {USEFT | NOUSEFT} | {LOGIN | NOLOGIN} | {REPLICATION | NOREPLICATION} | {INDEPENDENT | NOINDEPENDENT} | {VCADMIN | NOVCADMIN} | CONNECTION LIMIT connlimit | [ ENCRYPTED | UNENCRYPTED ] PASSWORD 'password' | [ ENCRYPTED | UNENCRYPTED ] IDENTIFIED BY 'password' [ REPLACE 'old_password' ] | [ ENCRYPTED | UNENCRYPTED ] PASSWORD { 'password' | DISABLE } | [ ENCRYPTED | UNENCRYPTED ] IDENTIFIED BY { 'password' [ REPLACE 'old_password' ] | DISABLE } | VALID BEGIN 'timestamp' | VALID UNTIL 'timestamp' | RESOURCE POOL 'respool' | USER GROUP 'groupuser' | PERM SPACE 'spacelimit' | TEMP SPACE 'tmpspacelimit' | SPILL SPACE 'spillspacelimit' | NODE GROUP logic_cluster_name | ACCOUNT { LOCK | UNLOCK } | PGUSER | AUTHINFO 'authinfo' | PASSWORD EXPIRATION period
- Rename a role.
1 2
ALTER ROLE role_name RENAME TO new_name;
- Set parameters for a role.
1 2
ALTER ROLE role_name [ IN DATABASE database_name ] SET configuration_parameter {{ TO | = } { value | DEFAULT } | FROM CURRENT};
- Reset parameters for a role.
1 2
ALTER ROLE role_name [ IN DATABASE database_name ] RESET {configuration_parameter|ALL};
Parameter Description
Parameter |
Description |
Value Range |
---|---|---|
role_name |
Specifies the name of the role to be modified. |
Name of an existing role. |
new_name |
Indicates the new name of a role. |
A string compliant with the identifier naming rules. |
CREATEDB | NOCREATEDB |
Defines a role's ability to create databases. If not specified, NOCREATEDB is the default value. A new role does not have the permission to create databases. |
- |
CREATEROLE | NOCREATEROLE |
Determines whether a role will be permitted to create new roles (that is, execute CREATE ROLE and CREATE USER). If not specified, NOCREATEROLE is the default value. A role with the CREATEROLE permission can also modify and delete other roles. |
- |
INHERIT | NOINHERIT |
Determines whether the role can inherit permissions of its group. You are not advised to execute them. |
- |
AUDITADMIN | NOAUDITADMIN |
Determines whether a role has the audit and management attributes. If not specified, NOAUDITADMIN is the default. |
- |
SYSADMIN | NOSYSADMIN |
Determines whether a new role is a system administrator. Roles having the SYSADMIN attribute have the highest permission. If not specified, NOSYSADMIN is the default value. |
- |
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. Default value NOUSEFT indicates that a new role cannot perform operations on foreign tables. |
- |
LOGIN | NOLOGIN |
Indicates whether a user can log in to the database. Only roles with the LOGIN attribute can log in to the 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 and independent roles. For a role with the INDEPENDENT attribute, administrators' rights to control and access this role are separated. Specific rules are as follows:
|
- |
VCADMIN | NOVCADMIN |
Defines the role of a logical cluster administrator. A logical cluster administrator has the following more permissions than common users:
|
- |
CONNECTION LIMIT |
Indicates the number of concurrent connections that a role can use on a single CN. To ensure the proper running of a cluster, the minimum value of CONNECTION LIMIT is the number of CNs in the cluster, because when a cluster runs ANALYZE on a CN, other CNs will connect to the running CN for metadata synchronization. For example, if there are three CNs in the cluster, set CONNECTION LIMIT to 3 or a larger value. |
Integers no less than –1. The default value –1 means no limit. |
ENCRYPTED | UNENCRYPTED |
Determines whether the password stored in the system will be encrypted. (If neither is specified, the password status is determined by password_encryption_type.) According to product security requirements, the password must be stored encrypted. Therefore, UNENCRYPTED is forbidden in GaussDB(DWS). If the password is encrypted using SHA256, it will be stored as it is, regardless of whether it is specified as ENCRYPTED or UNENCRYPTED. This is because the system cannot decrypt the specified encrypted password. This allows reloading of the encrypted password during dump/restore.
|
The password must:
|
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 a role, and the name belongs to the system catalog: pg_resource_pool. |
- |
USER GROUP 'groupuser' |
Creates a sub-user. |
- |
PERM SPACE |
Sets the storage space of the user permanent table. space_limit specifies the upper limit of the storage space of the permanent table. |
space_limit: A string consists of an integer and unit. The unit can be K/M/G/T/P. 0 indicates no limits. |
TEMP SPACE |
Sets the storage space of the user temporary table. tmpspacelimit specifies the storage space limit of the temporary table. |
tmpspacelimit: A string consists of an integer and unit. The unit can be K/M/G/T/P. 0 indicates no limits. |
SPILL SPACE |
Sets the operator disk flushing space of the user. spillspacelimit specifies the operator spilling space limit. |
spillspacelimit: A string consists of an integer and unit. The unit can be K/M/G/T/P. 0 indicates no limits. |
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. |
- |
ACCOUNT LOCK | ACCOUNT UNLOCK |
|
- |
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. PGUSER of a role cannot be modified in the current version. For details, see PGUSER Parameter Setting Suggestions. |
- |
AUTHINFO 'authinfo' |
Specifies the role authentication type. authinfo is the description character string, which is case sensitive. Only the LDAP type is supported. Its description character string is ldap. LDAP authentication is an external authentication mode. Therefore, PASSWORD DISABLE must be specified.
|
- |
PASSWORD EXPIRATION period |
Specifies the number of days before the login password of the role expires. You need to change the password before the password expires. If your login password expires, you cannot log in. Ask the administrator for a new password. |
An integer ranging from –1 to 999.
|
IN DATABASE database_name |
Modifies the parameters of a role in a specified database. |
- |
SET configuration_parameter |
Sets parameters for a role. The session parameters modified using the ALTER ROLE command is only for a specific role and is valid in the next session triggered by the role.
|
Values of configuration_parameter and value are listed in SET. |
RESET configuration_parameter/ALL |
The effect of clearing the configuration_parameter value is the same as setting it to DEFAULT. ALL indicates that all parameter values are cleared. |
- |
PGUSER Parameter Setting Suggestions
The PGUSER attribute is for compatibility with the connection process. It does not handle incompatibilities due to kernel differences between the product and Postgres.
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. Example:
1 2 3 4 5 6 7 |
# normaluser is a user that does not have the PGUSER attribute. psql is the Postgres client tool. pg@dws04:~> 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@dws04:~> psql -d postgres -p 8000 -h 10.11.12.13 -U pguser Password for user pguser: |
Examples
Create example roles r1, r2, and r3.
1 2 3 |
CREATE ROLE r1 IDENTIFIED BY '{Password}'; CREATE ROLE r2 WITH LOGIN AUTHINFO 'ldapcn=r2,cn=user,dc=lework,dc=com' PASSWORD DISABLE; CREATE ROLE r3 WITH LOGIN PASSWORD '{Password}' PASSWORD EXPIRATION 30; |
Modify the login permission of role r1.
1
|
ALTER ROLE r1 login; |
Change the password of role r1.
1
|
ALTER ROLE r1 IDENTIFIED BY '{new_Password}' REPLACE '{Password}'; |
Change the manager role to the system administrator.
1
|
ALTER ROLE r1 SYSADMIN; |
Modify the fulluser information of the LDAP authentication role.
1
|
ALTER ROLE r2 WITH LOGIN AUTHINFO 'ldapcn=role2,cn=user2,dc=func,dc=com' PASSWORD DISABLE; |
Change the validity period of the login password of the role to 90 days.
1
|
ALTER ROLE r3 PASSWORD EXPIRATION 90; |
Links
CREATE ROLE, DROP ROLE, and SET.
Feedback
Was this page helpful?
Provide feedbackThank you very much for your feedback. We will continue working to improve the documentation.See the reply and handling status in My Cloud VOC.
For any further questions, feel free to contact us through the chatbot.
Chatbot