A MySQL role is a named collection of privileges. Like user accounts, roles can have privileges granted to and revoked from them.
A user account can be granted roles, which grants to the account the privileges associated with each role. This enables assignment of sets of privileges to accounts and provides a convenient alternative to granting individual privileges, both for conceptualizing desired privilege assignments and implementing them.
The following list summarizes role-management capabilities provided by MySQL:
- CREATE ROLEand- DROP ROLEcreate and remove roles.
- GRANTand- REVOKEassign privileges to revoke privileges from user accounts and roles.
- SHOW GRANTSdisplays privilege and role assignments for user accounts and roles.
- SET DEFAULT ROLEspecifies which account roles are active by default.
- SET ROLEchanges the active roles within the current session.
- The - CURRENT_ROLE()function displays the active roles within the current session.
- The - mandatory_rolesand- activate_all_roles_on_loginsystem variables enable defining mandatory roles and automatic activation of granted roles when users log in to the server.
      For descriptions of individual role-manipulation statements
      (including the privileges required to use them), see
      Section 15.7.1, “Account Management Statements”. The following
      discussion provides examples of role usage. Unless otherwise
      specified, SQL statements shown here should be executed using a
      MySQL account with sufficient administrative privileges, such as
      the root account.
Consider this scenario:
- An application uses a database named - app_db.
- Associated with the application, there can be accounts for developers who create and maintain the application, and for users who interact with it. 
- Developers need full access to the database. Some users need only read access, others need read/write access. 
To avoid granting privileges individually to possibly many user accounts, create roles as names for the required privilege sets. This makes it easy to grant the required privileges to user accounts, by granting the appropriate roles.
        To create the roles, use the CREATE
        ROLE statement:
      
CREATE ROLE 'app_developer', 'app_read', 'app_write';
        Role names are much like user account names and consist of a
        user part and host part in
        '
        format. The host part, if omitted, defaults to
        user_name'@'host_name''%'. The user and host parts can be unquoted
        unless they contain special characters such as
        - or %. Unlike account
        names, the user part of role names cannot be blank. For
        additional information, see Section 8.2.5, “Specifying Role Names”.
      
        To assign privileges to the roles, execute
        GRANT statements using the same
        syntax as for assigning privileges to user accounts:
      
GRANT ALL ON app_db.* TO 'app_developer';
GRANT SELECT ON app_db.* TO 'app_read';
GRANT INSERT, UPDATE, DELETE ON app_db.* TO 'app_write';
        Now suppose that initially you require one developer account,
        two user accounts that need read-only access, and one user
        account that needs read/write access. Use
        CREATE USER to create the
        accounts:
      
CREATE USER 'dev1'@'localhost' IDENTIFIED BY 'dev1pass';
CREATE USER 'read_user1'@'localhost' IDENTIFIED BY 'read_user1pass';
CREATE USER 'read_user2'@'localhost' IDENTIFIED BY 'read_user2pass';
CREATE USER 'rw_user1'@'localhost' IDENTIFIED BY 'rw_user1pass';
        To assign each user account its required privileges, you could
        use GRANT statements of the same
        form as just shown, but that requires enumerating individual
        privileges for each user. Instead, use an alternative
        GRANT syntax that permits
        granting roles rather than privileges:
      
GRANT 'app_developer' TO 'dev1'@'localhost';
GRANT 'app_read' TO 'read_user1'@'localhost', 'read_user2'@'localhost';
GRANT 'app_read', 'app_write' TO 'rw_user1'@'localhost';
        The GRANT statement for the
        rw_user1 account grants the read and write
        roles, which combine to provide the required read and write
        privileges.
      
        The GRANT syntax for granting
        roles to an account differs from the syntax for granting
        privileges: There is an ON clause to assign
        privileges, whereas there is no ON clause to
        assign roles. Because the syntaxes are distinct, you cannot mix
        assigning privileges and roles in the same statement. (It is
        permitted to assign both privileges and roles to an account, but
        you must use separate GRANT
        statements, each with syntax appropriate to what is to be
        granted.) Roles cannot be granted to anonymous users.
      
        A role when created is locked, has no password, and is assigned
        the default authentication plugin. (These role attributes can be
        changed later with the ALTER USER
        statement, by users who have the global
        CREATE USER privilege.)
      
While locked, a role cannot be used to authenticate to the server. If unlocked, a role can be used to authenticate. This is because roles and users are both authorization identifiers with much in common and little to distinguish them. See also User and Role Interchangeability.
        It is possible to specify roles as mandatory by naming them in
        the value of the
        mandatory_roles system
        variable. The server treats a mandatory role as granted to all
        users, so that it need not be granted explicitly to any account.
      
        To specify mandatory roles at server startup, define
        mandatory_roles in your server
        my.cnf file:
      
[mysqld]
mandatory_roles='role1,role2@localhost,r3@%.example.com'
        To set and persist
        mandatory_roles at runtime, use
        a statement like this:
      
SET PERSIST mandatory_roles = 'role1,role2@localhost,r3@%.example.com';
        SET
        PERSIST sets a value for the running MySQL instance.
        It also saves the value, causing it to carry over to subsequent
        server restarts. To change the value for the running MySQL
        instance without having it carry over to subsequent restarts,
        use the GLOBAL keyword rather than
        PERSIST. See Section 15.7.6.1, “SET Syntax for Variable Assignment”.
      
        Setting mandatory_roles
        requires the ROLE_ADMIN
        privilege, in addition to the
        SYSTEM_VARIABLES_ADMIN privilege
        (or the deprecated SUPER
        privilege) normally required to set a global system variable.
      
        Mandatory roles, like explicitly granted roles, do not take
        effect until activated (see Activating Roles).
        At login time, role activation occurs for all granted roles if
        the activate_all_roles_on_login
        system variable is enabled, or for roles that are set as default
        roles otherwise. At runtime, SET
        ROLE activates roles.
      
        Roles named in the value of
        mandatory_roles cannot be
        revoked with REVOKE or dropped
        with DROP ROLE or
        DROP USER.
      
        To prevent sessions from being made system sessions by default,
        a role that has the SYSTEM_USER
        privilege cannot be listed in the value of the
        mandatory_roles system
        variable:
- If - mandatory_rolesis assigned a role at startup that has the- SYSTEM_USERprivilege, the server writes a message to the error log and exits.
- If - mandatory_rolesis assigned a role at runtime that has the- SYSTEM_USERprivilege, an error occurs and the- mandatory_rolesvalue remains unchanged.
        Even with this safeguard, it is better to avoid granting the
        SYSTEM_USER privilege through a
        role in order to guard against the possibility of privilege
        escalation.
      
        If a role named in
        mandatory_roles is not present
        in the mysql.user system table, the role is
        not granted to users. When the server attempts role activation
        for a user, it does not treat the nonexistent role as mandatory
        and writes a warning to the error log. If the role is created
        later and thus becomes valid, FLUSH
        PRIVILEGES may be necessary to cause the server to
        treat it as mandatory.
      
        SHOW GRANTS displays mandatory
        roles according to the rules described in
        Section 15.7.7.23, “SHOW GRANTS Statement”.
        To verify the privileges assigned to an account, use
        SHOW GRANTS. For example:
      
mysql> SHOW GRANTS FOR 'dev1'@'localhost';
+-------------------------------------------------+
| Grants for dev1@localhost                       |
+-------------------------------------------------+
| GRANT USAGE ON *.* TO `dev1`@`localhost`        |
| GRANT `app_developer`@`%` TO `dev1`@`localhost` |
+-------------------------------------------------+
        However, that shows each granted role without
        “expanding” it to the privileges the role
        represents. To show role privileges as well, add a
        USING clause naming the granted roles for
        which to display privileges:
      
mysql> SHOW GRANTS FOR 'dev1'@'localhost' USING 'app_developer';
+----------------------------------------------------------+
| Grants for dev1@localhost                                |
+----------------------------------------------------------+
| GRANT USAGE ON *.* TO `dev1`@`localhost`                 |
| GRANT ALL PRIVILEGES ON `app_db`.* TO `dev1`@`localhost` |
| GRANT `app_developer`@`%` TO `dev1`@`localhost`          |
+----------------------------------------------------------+Verify each other type of user similarly:
mysql> SHOW GRANTS FOR 'read_user1'@'localhost' USING 'app_read';
+--------------------------------------------------------+
| Grants for read_user1@localhost                        |
+--------------------------------------------------------+
| GRANT USAGE ON *.* TO `read_user1`@`localhost`         |
| GRANT SELECT ON `app_db`.* TO `read_user1`@`localhost` |
| GRANT `app_read`@`%` TO `read_user1`@`localhost`       |
+--------------------------------------------------------+
mysql> SHOW GRANTS FOR 'rw_user1'@'localhost' USING 'app_read', 'app_write';
+------------------------------------------------------------------------------+
| Grants for rw_user1@localhost                                                |
+------------------------------------------------------------------------------+
| GRANT USAGE ON *.* TO `rw_user1`@`localhost`                                 |
| GRANT SELECT, INSERT, UPDATE, DELETE ON `app_db`.* TO `rw_user1`@`localhost` |
| GRANT `app_read`@`%`,`app_write`@`%` TO `rw_user1`@`localhost`               |
+------------------------------------------------------------------------------+
        SHOW GRANTS displays mandatory
        roles according to the rules described in
        Section 15.7.7.23, “SHOW GRANTS Statement”.
        Roles granted to a user account can be active or inactive within
        account sessions. If a granted role is active within a session,
        its privileges apply; otherwise, they do not. To determine which
        roles are active within the current session, use the
        CURRENT_ROLE() function.
      
        By default, granting a role to an account or naming it in the
        mandatory_roles system variable
        value does not automatically cause the role to become active
        within account sessions. For example, because thus far in the
        preceding discussion no rw_user1 roles have
        been activated, if you connect to the server as
        rw_user1 and invoke the
        CURRENT_ROLE() function, the
        result is NONE (no active roles):
      
mysql> SELECT CURRENT_ROLE();
+----------------+
| CURRENT_ROLE() |
+----------------+
| NONE           |
+----------------+
        To specify which roles should become active each time a user
        connects to the server and authenticates, use
        SET DEFAULT ROLE. To set the
        default to all assigned roles for each account created earlier,
        use this statement:
      
SET DEFAULT ROLE ALL TO
  'dev1'@'localhost',
  'read_user1'@'localhost',
  'read_user2'@'localhost',
  'rw_user1'@'localhost';
        Now if you connect as rw_user1, the initial
        value of CURRENT_ROLE() reflects
        the new default role assignments:
      
mysql> SELECT CURRENT_ROLE();
+--------------------------------+
| CURRENT_ROLE()                 |
+--------------------------------+
| `app_read`@`%`,`app_write`@`%` |
+--------------------------------+
        To cause all explicitly granted and mandatory roles to be
        automatically activated when users connect to the server, enable
        the activate_all_roles_on_login
        system variable. By default, automatic role activation is
        disabled.
      
        Within a session, a user can execute SET
        ROLE to change the set of active roles. For example,
        for rw_user1:
      
mysql> SET ROLE NONE; SELECT CURRENT_ROLE();
+----------------+
| CURRENT_ROLE() |
+----------------+
| NONE           |
+----------------+
mysql> SET ROLE ALL EXCEPT 'app_write'; SELECT CURRENT_ROLE();
+----------------+
| CURRENT_ROLE() |
+----------------+
| `app_read`@`%` |
+----------------+
mysql> SET ROLE DEFAULT; SELECT CURRENT_ROLE();
+--------------------------------+
| CURRENT_ROLE()                 |
+--------------------------------+
| `app_read`@`%`,`app_write`@`%` |
+--------------------------------+
        The first SET ROLE statement
        deactivates all roles. The second makes
        rw_user1 effectively read only. The third
        restores the default roles.
      
        The effective user for stored program and view objects is
        subject to the DEFINER and SQL
        SECURITY attributes, which determine whether execution
        occurs in invoker or definer context (see
        Section 27.8, “Stored Object Access Control”):
- Stored program and view objects that execute in invoker context execute with the roles that are active within the current session. 
- Stored program and view objects that execute in definer context execute with the default roles of the user named in their - DEFINERattribute. If- activate_all_roles_on_loginis enabled, such objects execute with all roles granted to the- DEFINERuser, including mandatory roles. For stored programs, if execution should occur with roles different from the default, the program body can execute- SET ROLEto activate the required roles. This must be done with caution since the privileges assigned to roles can be changed.
Just as roles can be granted to an account, they can be revoked from an account:
REVOKE role FROM user;
        Roles named in the
        mandatory_roles system variable
        value cannot be revoked.
      
        REVOKE can also be applied to a
        role to modify the privileges granted to it. This affects not
        only the role itself, but any account granted that role. Suppose
        that you want to temporarily make all application users read
        only. To do this, use REVOKE to
        revoke the modification privileges from the
        app_write role:
      
REVOKE INSERT, UPDATE, DELETE ON app_db.* FROM 'app_write';
        As it happens, that leaves the role with no privileges at all,
        as can be seen using SHOW GRANTS
        (which demonstrates that this statement can be used with roles,
        not just users):
      
mysql> SHOW GRANTS FOR 'app_write';
+---------------------------------------+
| Grants for app_write@%                |
+---------------------------------------+
| GRANT USAGE ON *.* TO `app_write`@`%` |
+---------------------------------------+
        Because revoking privileges from a role affects the privileges
        for any user who is assigned the modified role,
        rw_user1 now has no table modification
        privileges (INSERT,
        UPDATE, and
        DELETE are no longer present):
      
mysql> SHOW GRANTS FOR 'rw_user1'@'localhost'
       USING 'app_read', 'app_write';
+----------------------------------------------------------------+
| Grants for rw_user1@localhost                                  |
+----------------------------------------------------------------+
| GRANT USAGE ON *.* TO `rw_user1`@`localhost`                   |
| GRANT SELECT ON `app_db`.* TO `rw_user1`@`localhost`           |
| GRANT `app_read`@`%`,`app_write`@`%` TO `rw_user1`@`localhost` |
+----------------------------------------------------------------+
        In effect, the rw_user1 read/write user has
        become a read-only user. This also occurs for any other accounts
        that are granted the app_write role,
        illustrating how use of roles makes it unnecessary to modify
        privileges for individual accounts.
      
To restore modification privileges to the role, simply re-grant them:
GRANT INSERT, UPDATE, DELETE ON app_db.* TO 'app_write';
        Now rw_user1 again has modification
        privileges, as do any other accounts granted the
        app_write role.
        To drop roles, use DROP ROLE:
      
DROP ROLE 'app_read', 'app_write';Dropping a role revokes it from every account to which it was granted.
        Roles named in the
        mandatory_roles system variable
        value cannot be dropped.
        As has been hinted at earlier for SHOW
        GRANTS, which displays grants for user accounts or
        roles, accounts and roles can be used interchangeably.
      
        One difference between roles and users is that
        CREATE ROLE creates an
        authorization identifier that is locked by default, whereas
        CREATE USER creates an
        authorization identifier that is unlocked by default. You should
        keep in mind that this distinction is not immutable; a user with
        appropriate privileges can lock or unlock roles or (other) users
        after they have been created.
      
        If a database administrator has a preference that a specific
        authorization identifier must be a role, a name scheme can be
        used to communicate this intention. For example, you could use a
        r_ prefix for all authorization identifiers
        that you intend to be roles and nothing else.
      
Another difference between roles and users lies in the privileges available for administering them:
- The - CREATE ROLEand- DROP ROLEprivileges enable only use of the- CREATE ROLEand- DROP ROLEstatements, respectively.
- The - CREATE USERprivilege enables use of the- ALTER USER,- CREATE ROLE,- CREATE USER,- DROP ROLE,- DROP USER,- RENAME USER, and- REVOKE ALL PRIVILEGESstatements.
        Thus, the CREATE ROLE and
        DROP ROLE privileges are not as
        powerful as CREATE USER and may
        be granted to users who should only be permitted to create and
        drop roles, and not perform more general account manipulation.
      
With regard to privileges and interchangeability of users and roles, you can treat a user account like a role and grant that account to another user or a role. The effect is to grant the account's privileges and roles to the other user or role.
This set of statements demonstrates that you can grant a user to a user, a role to a user, a user to a role, or a role to a role:
CREATE USER 'u1';
CREATE ROLE 'r1';
GRANT SELECT ON db1.* TO 'u1';
GRANT SELECT ON db2.* TO 'r1';
CREATE USER 'u2';
CREATE ROLE 'r2';
GRANT 'u1', 'r1' TO 'u2';
GRANT 'u1', 'r1' TO 'r2';
        The result in each case is to grant to the grantee object the
        privileges associated with the granted object. After executing
        those statements, each of u2 and
        r2 have been granted privileges from a user
        (u1) and a role (r1):
      
mysql> SHOW GRANTS FOR 'u2' USING 'u1', 'r1';
+-------------------------------------+
| Grants for u2@%                     |
+-------------------------------------+
| GRANT USAGE ON *.* TO `u2`@`%`      |
| GRANT SELECT ON `db1`.* TO `u2`@`%` |
| GRANT SELECT ON `db2`.* TO `u2`@`%` |
| GRANT `u1`@`%`,`r1`@`%` TO `u2`@`%` |
+-------------------------------------+
mysql> SHOW GRANTS FOR 'r2' USING 'u1', 'r1';
+-------------------------------------+
| Grants for r2@%                     |
+-------------------------------------+
| GRANT USAGE ON *.* TO `r2`@`%`      |
| GRANT SELECT ON `db1`.* TO `r2`@`%` |
| GRANT SELECT ON `db2`.* TO `r2`@`%` |
| GRANT `u1`@`%`,`r1`@`%` TO `r2`@`%` |
+-------------------------------------+The preceding example is illustrative only, but interchangeability of user accounts and roles has practical application, such as in the following situation: Suppose that a legacy application development project began before the advent of roles in MySQL, so all user accounts associated with the project are granted privileges directly (rather than granted privileges by virtue of being granted roles). One of these accounts is a developer account that was originally granted privileges as follows:
CREATE USER 'old_app_dev'@'localhost' IDENTIFIED BY 'old_app_devpass';
GRANT ALL ON old_app.* TO 'old_app_dev'@'localhost';If this developer leaves the project, it becomes necessary to assign the privileges to another user, or perhaps multiple users if development activities have expanded. Here are some ways to deal with the issue:
- Without using roles: Change the account password so the original developer cannot use it, and have a new developer use the account instead: - ALTER USER 'old_app_dev'@'localhost' IDENTIFIED BY 'new_password';
- Using roles: Lock the account to prevent anyone from using it to connect to the server: - ALTER USER 'old_app_dev'@'localhost' ACCOUNT LOCK;- Then treat the account as a role. For each developer new to the project, create a new account and grant to it the original developer account: - CREATE USER 'new_app_dev1'@'localhost' IDENTIFIED BY 'new_password'; GRANT 'old_app_dev'@'localhost' TO 'new_app_dev1'@'localhost';- The effect is to assign the original developer account privileges to the new account.