Updated on 2025-10-23 GMT+08:00

ALTER ROLE

Description

Modifies role attributes.

Precautions

None

Syntax

  • Modify the permissions of a role.
    ALTER ROLE role_name [ [ WITH ] option [ ... ] ];

    • The option clause for granting permissions is as follows:
      {CREATEDB | NOCREATEDB}
          | {CREATEROLE | NOCREATEROLE}
          | {AUDITADMIN | NOAUDITADMIN}
          | {SYSADMIN | NOSYSADMIN}
          | {MONADMIN | NOMONADMIN}
          | {OPRADMIN | NOOPRADMIN}
          | {POLADMIN | NOPOLADMIN}
          | {USEFT | NOUSEFT}
          | {INHERIT | NOINHERIT}
          | {LOGIN | NOLOGIN}
          | {PERSISTENCE | NOPERSISTENCE}
          | CONNECTION LIMIT connlimit
          | PASSWORD { 'password' [EXPIRED] | DISABLE }
          | IDENTIFIED BY { 'password' [ REPLACE 'old_password' | EXPIRED ] | DISABLE }
          | VALID BEGIN 'timestamp'
          | VALID UNTIL 'timestamp'
          | USER GROUP 'groupuser'
          | NODE GROUP logic_cluster_name
          | ACCOUNT { LOCK | UNLOCK }
  • Rename a role.
    ALTER ROLE role_name 
        RENAME TO new_name;

  • Lock or unlock.
    ALTER ROLE role_name 
        ACCOUNT { LOCK | UNLOCK };

  • Set parameters for a role.
    ALTER ROLE role_name [ IN DATABASE database_name ]
        SET configuration_parameter {{ TO | = } { value | DEFAULT } | FROM CURRENT};

  • Reset all configuration parameters of a role.
    ALTER ROLE role_name
        [ IN DATABASE database_name ] RESET ALL;

Parameters

  • role_name

    Specifies a role name.

    Value range: an existing role name. For details, see •role_name.

  • IN DATABASE database_name

    Modifies the parameters of a role in a specified database.

  • SET configuration_parameter {{ TO | = } { value | DEFAULT } | FROM CURRENT}

    Sets parameters for a role. The session parameters modified using ALTER ROLE is only for a specific role and is valid in the next session triggered by the role.

    Value range:

    For details about the values of configuration_parameter and value, see SET.

    DEFAULT: clears the value of configuration_parameter. configuration_parameter will inherit the default value of the new session generated for the role.

    FROM CURRENT: uses the value of configuration_parameter of the current session.

  • RESET ALL

    Restores all values of configuration_parameter to default values.

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

    In the current version, the PGUSER attribute of a role cannot be modified.

  • {PASSWORD|IDENTIFIED BY} 'password'

    Resets or changes the user password. Except the initial user, other administrators and common users need to enter the correct old password when changing their own passwords. Only the initial user, the system administrator (sysadmin) when separation of duties is disabled, or the user who has the permission to create users (CREATEROLE) can reset the password of a common user without entering the old password. The initial user can reset passwords of system administrators. A system administrator cannot reset passwords of other system administrators. Be enclosed by single quotation marks.

  • EXPIRED

    Invalidates the password. Only the initial user, the system administrator (sysadmin), or user who has the permission to create a user (CREATEROLE) can invalidate the user password. The system administrator can invalidate the password of itself or other system administrators only when the separation of duties is disabled. The password of the initial user cannot be invalidated.

    The user whose password is invalid can log in to the database but cannot perform the query operation. The query operation can be performed only after the password is changed or the administrator resets the password.

For details about other parameters, see Parameters in CREATE ROLE.

Examples

See Examples in CREATE ROLE.

Helpful Links

CREATE ROLE, DROP ROLE, SET ROLE