Skip to content

Latest commit

 

History

History
158 lines (114 loc) · 4.38 KB

sql-statement-set-default-role.md

File metadata and controls

158 lines (114 loc) · 4.38 KB
title summary
SET DEFAULT ROLE | TiDB SQL Statement Reference
An overview of the usage of SET DEFAULT ROLE for the TiDB database.

SET DEFAULT ROLE

This statement sets a specific role to be applied to a user by default. Thus, they will automatically have the permissions associated with a role without having to execute SET ROLE <rolename> or SET ROLE ALL.

Synopsis

SetDefaultRoleStmt:

SetDefaultRoleStmt

SetDefaultRoleOpt:

SetDefaultRoleOpt

RolenameList:

RolenameList

UsernameList:

UsernameList

Examples

Connect to TiDB as the root user:

mysql -h 127.0.0.1 -P 4000 -u root

Create a new role analyticsteam and a new user jennifer:

CREATE ROLE analyticsteam;
Query OK, 0 rows affected (0.02 sec)

GRANT SELECT ON test.* TO analyticsteam;
Query OK, 0 rows affected (0.02 sec)

CREATE USER jennifer;
Query OK, 0 rows affected (0.01 sec)

GRANT analyticsteam TO jennifer;
Query OK, 0 rows affected (0.01 sec)

Connect to TiDB as the jennifer user:

mysql -h 127.0.0.1 -P 4000 -u jennifer

Note that by default jennifer needs to execute SET ROLE analyticsteam in order to be able to use the privileges associated with the analyticsteam role:

SHOW GRANTS;
+---------------------------------------------+
| Grants for User                             |
+---------------------------------------------+
| GRANT USAGE ON *.* TO 'jennifer'@'%'        |
| GRANT 'analyticsteam'@'%' TO 'jennifer'@'%' |
+---------------------------------------------+
2 rows in set (0.00 sec)

SHOW TABLES in test;
ERROR 1044 (42000): Access denied for user 'jennifer'@'%' to database 'test'
SET ROLE analyticsteam;
Query OK, 0 rows affected (0.00 sec)

SHOW GRANTS;
+---------------------------------------------+
| Grants for User                             |
+---------------------------------------------+
| GRANT USAGE ON *.* TO 'jennifer'@'%'        |
| GRANT Select ON test.* TO 'jennifer'@'%'    |
| GRANT 'analyticsteam'@'%' TO 'jennifer'@'%' |
+---------------------------------------------+
3 rows in set (0.00 sec)

SHOW TABLES IN test;
+----------------+
| Tables_in_test |
+----------------+
| t1             |
+----------------+
1 row in set (0.00 sec)

Connect to TiDB as the root user:

mysql -h 127.0.0.1 -P 4000 -u root

The statement SET DEFAULT ROLE can be used to associate the role analyticsteam to jennifer:

SET DEFAULT ROLE analyticsteam TO jennifer;
Query OK, 0 rows affected (0.02 sec)

Connect to TiDB as the jennifer user:

mysql -h 127.0.0.1 -P 4000 -u jennifer

After this, the user jennifer has the privileges associated with the role analyticsteam and jennifer does not have to execute the statement SET ROLE:

SHOW GRANTS;
+---------------------------------------------+
| Grants for User                             |
+---------------------------------------------+
| GRANT USAGE ON *.* TO 'jennifer'@'%'        |
| GRANT Select ON test.* TO 'jennifer'@'%'    |
| GRANT 'analyticsteam'@'%' TO 'jennifer'@'%' |
+---------------------------------------------+
3 rows in set (0.00 sec)

SHOW TABLES IN test;
+----------------+
| Tables_in_test |
+----------------+
| t1             |
+----------------+
1 row in set (0.00 sec)

SET DEFAULT ROLE will not automatically GRANT the associated role to the user. Attempting to SET DEFAULT ROLE for a role that jennifer does not have granted results in the following error:

SET DEFAULT ROLE analyticsteam TO jennifer;
ERROR 3530 (HY000): `analyticsteam`@`%` is is not granted to jennifer@%

MySQL compatibility

This statement is understood to be fully compatible with roles, which are a feature of MySQL 8.0. Any compatibility differences should be reported via an issue on GitHub.

See also