Updated on 2025-07-22 GMT+08:00

ALTER USER

Function

ALTER USER modifies the attributes of a database user.

Precautions

Session parameters modified by ALTER USER apply to a specified user and take effect in the next session.

Syntax

  • Modify user rights or other information.
    1
    ALTER USER user_name [ [ WITH ] option [ ... ] ];
    

    The option clause 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
    { 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' | 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
    
  • Change the user name.
    1
    2
    ALTER USER user_name 
        RENAME TO new_name;
    
  • Change the value of a specified parameter associated with the user.
    1
    2
    ALTER USER user_name 
        SET configuration_parameter { { TO | = } { value | DEFAULT } | FROM CURRENT };
    
  • Reset the value of a specified parameter associated with the user.
    1
    2
    ALTER USER user_name 
        RESET { configuration_parameter | ALL };
    

Parameter Description

Table 1 ALTER USER parameters

Parameter

Description

Value Range/Default Value

user_name

Specifies the username to be changed.

Valid username.

new_name

Specifies the new name of a user.

A string compliant with the identifier naming rules.

CREATEDB | NOCREATEDB

Controls whether a new user can create a database.

A new user does not have the permission to create a database by default.

Default value: NOCREATEDB

CREATEROLE | NOCREATEROLE

Controls whether a user can create new users or roles using CREATE ROLE and CREATE USER. A user with the CREATEROLE permission can also modify and delete other users.

Default value: NOCREATEROLE

INHERIT | NOINHERIT

Controls whether a user can inherit the permissions of its group. You are not advised to use it.

-

AUDITADMIN | NOAUDITADMIN

Defines whether a user has the audit administrator attribute.

Default value: NOAUDITADMIN

SYSADMIN | NOSYSADMIN

Controls whether a user is a system administrator. A user with the SYSADMIN attribute has the highest permission in the system.

Default value: NOSYSADMIN

USEFT | NOUSEFT

Controls whether a user can perform operations on foreign tables, such as creating, deleting, modifying, and reading/witting foreign tables.

The default value is NOUSEFT, indicating that new users cannot perform operations on foreign tables by default.

The new user does not have the permission to perform operations on foreign tables.

-

LOGIN | NOLOGIN

Controls whether a user can log in to the database. Only users with the LOGIN attribute can log in to the database.

Default value: LOGIN

REPLICATION | NOREPLICATION

Controls whether a user is allowed to initiate streaming replication or put the system in and out of backup mode. A user with the REPLICATION attribute is only used for replication.

Default value: NOREPLICATION

INDEPENDENT | NOINDEPENDENT

Defines private and independent users. For a user 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 user.
  • Without the authorization of the INDEPENDENT user, the administrator has no right to modify its inheritance relationship.
  • The administrator does not have the permission to change the owner of the table object of an INDEPENDENT user.
  • The administrator does not have the permission to remove the INDEPENDENT attribute of an INDEPENDENT user.
  • The administrator does not have the permission to change the database password of an INDEPENDENT user. An INDEPENDENT must manage its own password. If the password is lost, it cannot be reset.
  • The SYSADMIN attribute of a user cannot be changed to the INDEPENDENT attribute.

-

VCADMIN | NOVCADMIN

Defines 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

Specifies the number of concurrent connections that can be used by a user on a single CN.

To ensure that a cluster can run normally, the minimum value of CONNECTION LIMIT is the number of CNs in the cluster, because when you run ANALYZE on a CN of the cluster, other CNs will connect to the running CN for metadata synchronization. For example, if there are three CNs in a cluster, set CONNECTION LIMIT to 3 or a larger value.

Value range: integers no less than –1.

Default value: -1, indicating there is 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.

  • password: login password.
  • DISABLE: Users can change their own passwords unless the passwords are disabled. You can use DISABLE to disable the password of a user. 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, Kerberos authentication, or LDAP authentication. Only administrators can enable or disable passwords. Common users cannot disable the password of an initial user. To enable a password, run ALTER USER and specify the password.

The password must:

  • Contain at least eight characters.
  • Differ from the username or it in reverse order.
  • Contain at least three types of the following characters: uppercase letters (A-Z), lowercase letters (a-z), digits (0-9), and special characters such as ~!@#$ %^&*()-_=+\|[{}];:,<.>/? (If you use a character that is not in the specified range, an alarm is generated, but the character can still be created.)

VALID BEGIN

Sets the timestamp when a user takes effect. If this clause is omitted, there is no restriction on when the user takes effect.

-

VALID UNTIL

Sets an expiration timestamp for an account. After the specified time, the account cannot be used. If this clause is omitted, it means the account will never expire

-

RESOURCE POOL

Sets the name of the resource pool used by a user. The name is from the system catalog pg_resource_pool.

-

USER GROUP 'groupuser'

Creates a subuser.

-

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

Locks or unlocks an account.

  • ACCOUNT LOCK: locks an account to forbid login to databases.
  • ACCOUNT UNLOCK: unlocks an account to allow login to databases.

-

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 user cannot be modified in the current version. For details, see PGUSER Parameter Setting Suggestions.

-

AUTHINFO 'authinfo'

This attribute is used to specify the user 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.

  • Additional information about LDAP authentication can be added to authinfo, for example, fulluser in LDAP authentication, which is equivalent to ldapprefix+username+ldapsuffix. If the content of authinfo is ldap, the user authentication type is LDAP. In this case, the ldapprefix and ldapsuffix information is provided by the corresponding record in the pg_hba.conf file.
  • When executing ALTER ROLE, users are not allowed to change the authentication type. Only LDAP users are allowed to modify LDAP attributes.

-

PASSWORD EXPIRATION period

Number of days before the login password of the role expires. The user needs to change the password in time before the login password expires. If the login password expires, the user cannot log in to the system. In this case, the user needs to ask the administrator to set a new login password.

The value is an integer ranging from –1 to 999.

  • Default value –1 indicates that there is no restriction.
  • 0 indicates that the login password expires immediately.

SET configuration_parameter

Sets the session parameters of a user. The session parameters modified by running the ALTER USER command apply only to the specified user and are valid in the next session started by the user.

  • DEFAULT clears the value of configuration_parameter. The value of the configuration_parameter parameter inherits the default value of the new session of the role.
  • FROM CURRENT uses the value of configuration_parameter of the current session.

For details about the values of configuration_parameter and value, see 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 with the PGUSER attribute have a different authentication method. Open-source clients might reveal the PGUSER attribute through error messages. You are advised to use the client provided with the 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 user u1.

1
2
DROP USER IF EXISTS u1 CASCADE;
CREATE USER u1 PASSWORD '{Password}';

Change the login password of user u1.

1
ALTER USER u1 IDENTIFIED BY '{new_Password}' REPLACE '{Password}';

Add the CREATEROLE permission to user u1.

1
ALTER USER u1 CREATEROLE;

Set the maximum number of database connections of user u1 to 10.

1
ALTER USER u1 with  CONNECTION LIMIT 10;

Set the enable_seqscan parameter of the session associated with user u1 to on. The setting takes effect in the next session.

1
ALTER USER u1 SET enable_seqscan TO on;

Reset the enable_seqscan parameter for user u1.

1
ALTER USER u1 RESET enable_seqscan;

Lock the u1 account.

1
ALTER USER u1 ACCOUNT LOCK;