MySQL8新增了角色(role)的概念,使账号权限的管理,更加灵活方便。所谓角色,就是一些权限的集合。然后再把该集合授权给某个账户(往往是某一批账户,因为账号会绑定IP,不同的IP,虽然账号名相同被视为不同账号),这样当我们需要对这些账号减少或增加权限时,只需要修改权限集合(role)即可,不用单个账号多次修改。这确实使DBA的运维轻松了不少。
下面我们看下role是如何使用的。
创建角色
比如开发环境账户需要某库的所有权限,生产环境账号往往需要增删改查这些权限,我们可以单独为这些权限建一个role.如果有读写分离,还可以建两个读和写的role。
create role 'app_dev','app_read','app_write';
mysql8[(none)]>show grants for 'app_dev';
+-------------------------------------+
| Grants for app_dev@% |
+-------------------------------------+
| GRANT USAGE ON *.* TO `app_dev`@`%` |
+-------------------------------------+
创建角色时同样可以绑定Host(默认%), 即角色名分为name + host两部分,这和账号没有什么区别。
同样创建的角色也和账号一样保存在mysql.user表中。通过查询此表可以看到角色的信息:
mysql8[(none)]>select * from mysql.user;
+-----------+------------------+-------------+-------------+-------------+-------------+-------------+-----------+-------------+---------------+--------------+-----------+------------+-----------------+------------+------------+--------------+------------+-----------------------+------------------+--------------+-----------------+------------------+------------------+----------------+---------------------+--------------------+------------------+------------+--------------+------------------------+----------+------------+-------------+--------------+---------------+-------------+-----------------+----------------------+-----------------------+------------------------------------------------------------------------+------------------+-----------------------+-------------------+----------------+------------------+----------------+------------------------+---------------------+
| Host | User | Select_priv | Insert_priv | Update_priv | Delete_priv | Create_priv | Drop_priv | Reload_priv | Shutdown_priv | Process_priv | File_priv | Grant_priv | References_priv | Index_priv | Alter_priv | Show_db_priv | Super_priv | Create_tmp_table_priv | Lock_tables_priv | Execute_priv | Repl_slave_priv | Repl_client_priv | Create_view_priv | Show_view_priv | Create_routine_priv | Alter_routine_priv | Create_user_priv | Event_priv | Trigger_priv | Create_tablespace_priv | ssl_type | ssl_cipher | x509_issuer | x509_subject | max_questions | max_updates | max_connections | max_user_connections | plugin | authentication_string | password_expired | password_last_changed | password_lifetime | account_locked | Create_role_priv | Drop_role_priv | Password_reuse_history | Password_reuse_time |
+-----------+------------------+-------------+-------------+-------------+-------------+-------------+-----------+-------------+---------------+--------------+-----------+------------+-----------------+------------+------------+--------------+------------+-----------------------+------------------+--------------+-----------------+------------------+------------------+----------------+---------------------+--------------------+------------------+------------+--------------+------------------------+----------+------------+-------------+--------------+---------------+-------------+-----------------+----------------------+-----------------------+------------------------------------------------------------------------+------------------+-----------------------+-------------------+----------------+------------------+----------------+------------------------+---------------------+
| % | app_dev | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | | | | | 0 | 0 | 0 | 0 | caching_sha2_password | | Y | 2018-06-14 11:27:35 | NULL | Y | N | N | NULL | NULL |
| % | app_read | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | | | | | 0 | 0 | 0 | 0 | caching_sha2_password | | Y | 2018-06-14 11:27:35 | NULL | Y | N | N | NULL | NULL |
| % | app_write | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | | | | | 0 | 0 | 0 | 0 | caching_sha2_password | | Y | 2018-06-14 11:27:35 | NULL | Y | N | N | NULL | NULL |
| % | repl | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | N | Y | N | N | N | N | N | N
给角色授权
上面我们建了三个role,但这三个role都只有usage权限,我们还需要对角色进行授权。授权方式与给账号授权是完全一样的。
mysql8[(none)]>grant select , insert,update,delete on test.* to app_dev;
Query OK, 0 rows affected (0.02 sec)
mysql8[(none)]>grant select on test.* to app_read;
Query OK, 0 rows affected (0.10 sec)
mysql8[(none)]>show grants for app_read;
+--------------------------------------------+
| Grants for app_read@% |
+--------------------------------------------+
| GRANT USAGE ON *.* TO `app_read`@`%` |
| GRANT SELECT ON `test`.* TO `app_read`@`%` |
+--------------------------------------------+
2 rows in set (0.00 sec)
mysql8[(none)]>show grants for app_dev;
+-------------------------------------------------------------------+
| Grants for app_dev@% |
+-------------------------------------------------------------------+
| GRANT USAGE ON *.* TO `app_dev`@`%` |
| GRANT SELECT, INSERT, UPDATE, DELETE ON `test`.* TO `app_dev`@`%` |
+-------------------------------------------------------------------+
授权后我们看到各角色已经具有了相应的权限。
将角色授权于账号
下面我们创建具体的账号,并将相应的role授权给账号。
mysql8[(none)]>create user dev01 identified with mysql_native_password by 'dev01';
Query OK, 0 rows affected (0.04 sec)
mysql8[(none)]>grant app_dev to dev01;
Query OK, 0 rows affected (0.05 sec)
mysql8[(none)]>show grants for dev01;
+------------------------------------+
| Grants for dev01@% |
+------------------------------------+
| GRANT USAGE ON *.* TO `dev01`@`%` |
| GRANT `app_dev`@`%` TO `dev01`@`%` |
+------------------------------------+
我们创建了一个账号dev01,并授权角色app_dev, 执行show grants 查看权限时,看到的是角色,并不是具体的权限。如果要查看具体的权限则需要这样执行show grants.
mysql8[(none)]>show grants for dev01 using app_dev;
+-----------------------------------------------------------------+
| Grants for dev01@% |
+-----------------------------------------------------------------+
| GRANT USAGE ON *.* TO `dev01`@`%` |
| GRANT SELECT, INSERT, UPDATE, DELETE ON `test`.* TO `dev01`@`%` |
| GRANT `app_dev`@`%` TO `dev01`@`%` |
+-----------------------------------------------------------------+
通过使用using app_dev,会将账号和角色的权限一并显示。
我们给角色app_dev添加create权限
mysql8[(none)]>grant create on test.* to app_dev;
Query OK, 0 rows affected (0.10 sec)
mysql8[(none)]>show grants for dev01 using app_dev;
+-------------------------------------------------------------------------+
| Grants for dev01@% |
+-------------------------------------------------------------------------+
| GRANT USAGE ON *.* TO `dev01`@`%` |
| GRANT SELECT, INSERT, UPDATE, DELETE, CREATE ON `test`.* TO `dev01`@`%` |
| GRANT `app_dev`@`%` TO `dev01`@`%` |
+-------------------------------------------------------------------------+
3 rows in set (0.00 sec)
可以看到给角色添加权限后,dev01账号也具有了create权限。
激活角色
上面的一些列操作貌似完美,dev02账号可以使用了,其实还不行!使用dev01账号登陆:
mysql> show grants for dev01 using app_dev;
+-------------------------------------------------------------------------+
| Grants for dev01@% |
+-------------------------------------------------------------------------+
| GRANT USAGE ON *.* TO `dev01`@`%` |
| GRANT SELECT, INSERT, UPDATE, DELETE, CREATE ON `test`.* TO `dev01`@`%` |
| GRANT `app_dev`@`%` TO `dev01`@`%` |
+-------------------------------------------------------------------------+
3 rows in set (0.00 sec)
mysql> show databases;
+--------------------+
| Database |
+--------------------+
| information_schema |
+--------------------+
1 row in set (0.01 sec)
发现权限也有,但并看不到test库,什么也无法执行。为什么呢?角色没有被激活
mysql> select current_role()
-> ;
+----------------+
| current_role() |
+----------------+
| NONE |
+----------------+
1 row in set (0.00 sec)
执行select current_role()发现是None. 所授权的角色并没有被激活,因此这个账号 还是废柴一个。
对账号激活权限也很简单
mysql8[(none)]>set default role all to dev01;
Query OK, 0 rows affected (0.06 sec)
这样对dev01授予的所有角色都会被激活。再使用dev01登陆就正常访问了。
mysql> show databases;
+--------------------+
| Database |
+--------------------+
| information_schema |
| test |
+--------------------+
2 rows in set (0.01 sec)
mysql> select current_role();
+----------------+
| current_role() |
+----------------+
| `app_dev`@`%` |
+----------------+
1 row in set (0.00 sec)
可以看到当前激活的角色为app_dev.
感觉流程太繁琐了,都授权完了还要激活,但MySQL8 提供已一个参数,可以使角色在账号登陆后自动被激活。
mysql8[(none)]>show global variables like 'activate_all_roles_on_login';
+-----------------------------+-------+
| Variable_name | Value |
+-----------------------------+-------+
| activate_all_roles_on_login | OFF |
+-----------------------------+-------+
1 row in set (0.01 sec)
mysql8[(none)]>set global activate_all_roles_on_login=ON;
Query OK, 0 rows affected (0.00 sec)
把activate_all_roles_on_login设置为ON就可以了。
mysql8[(none)]>create user query identified with mysql_native_password by 'query';
Query OK, 0 rows affected (0.04 sec)
mysql8[(none)]>grant app_read to query;
Query OK, 0 rows affected (0.06 sec)
mysql8[(none)]>show grants for query using app_read;
+-----------------------------------------+
| Grants for query@% |
+-----------------------------------------+
| GRANT USAGE ON *.* TO `query`@`%` |
| GRANT SELECT ON `test`.* TO `query`@`%` |
| GRANT `app_read`@`%` TO `query`@`%` |
+-----------------------------------------+
3 rows in set (0.00 sec)
mysql8[(none)]>exit
使用query账号登陆
mysql> show databases;
+--------------------+
| Database |
+--------------------+
| information_schema |
| test |
+--------------------+
2 rows in set (0.00 sec)
mysql> select current_user();
+----------------+
| current_user() |
+----------------+
| query@% |
+----------------+
1 row in set (0.00 sec)
mysql> select current_role();
+----------------+
| current_role() |
+----------------+
| `app_read`@`%` |
+----------------+
1 row in set (0.00 sec)
可以看到角色已被激活。
角色和账号交互使用
角色和账号没有什么区别,可以把一个账号当做一个角色,将其授权给其它账号。详见MySQL 官方文档
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';
这也太灵活了吧? 我惊掉了下巴!