# 1、問題描述 用戶 `show grants` 顯示只有連接許可權,但該用戶卻能執行 sbtest.*下的所有操作 ```sql GreatSQL> \s ... Server version: 8.0.32-24 GreatSQL, Release 24, Revision 3714067bc8 ...
1、問題描述
用戶 show grants
顯示只有連接許可權,但該用戶卻能執行 sbtest.*下的所有操作
GreatSQL> \s
...
Server version: 8.0.32-24 GreatSQL, Release 24, Revision 3714067bc8c
...
GreatSQL> show grants;
+---------------------------------------+
| Grants for user1@172.% |
+---------------------------------------+
| GRANT USAGE ON *.* TO `user1`@`172.%` |
+---------------------------------------+
1 row in set (0.00 sec)
GreatSQL> select * from sbtest.sbtest1 limit 1;
+----+-----+-------------------------------------------------------------------------------------------------------------------------+-------------------------------------------------------------+
| id | k | c | pad |
+----+-----+-------------------------------------------------------------------------------------------------------------------------+-------------------------------------------------------------+
| 1 | 250 | 50739423477-59896895752-91121550334-25071371310-03454727381-25307272676-12883025003-48844794346-97662793974-67443907837 | 10824941535-62754685647-36430831520-45812593797-70371571680 |
+----+-----+-------------------------------------------------------------------------------------------------------------------------+-------------------------------------------------------------+
1 row in set (0.00 sec)
2、官方文檔
MySQL 官方手冊,有這樣一段話
https://dev.mysql.com/doc/refman/8.0/en/show-grants.html
SHOW GRANTS
does not display privileges that are available to the named account but are granted to a different account. For example, if an anonymous account exists, the named account might be able to use its privileges, butSHOW GRANTS
does not display them.
Percona Server 官方手冊,有類似一段話
https://docs.percona.com/percona-server/8.0/management/extended_show_grants.html
In Oracle MySQLSHOW GRANTS
displays only the privileges granted explicitly to the named account. Other privileges might be available to the account, but they are not displayed. For example, if an anonymous account exists, the named account might be able to use its privileges, butSHOW GRANTS
will not display them. Percona Server for MySQL offers theSHOW EFFECTIVE GRANTS
command to display all the effectively available privileges to the account, including those granted to a different account.
概括如下:
- 用戶 A 的 user 與用戶 B 的 user 相同,或者用戶 A 是匿名用戶
- 用戶 B 的 host 範圍是用戶 A 的 host 範圍的子集
滿足上述兩個條件,此時用戶 B 擁有顯式授予給用戶 A 的許可權,但 SHOW GRANTS
不會顯示這部分許可權。在 Percona Server 可以通過 SHOW EFFECTIVE GRANTS
查看。
3、測試驗證
3.1、同 user 用戶
1)、創建用戶並授權
# 創建用戶
GreatSQL> CREATE USER grantee@localhost IDENTIFIED BY 'grantee1';
Query OK, 0 rows affected (0.05 sec)
GreatSQL> CREATE USER grantee@'%' IDENTIFIED BY 'grantee2';
Query OK, 0 rows affected (0.01 sec)
# 創建資料庫
GreatSQL> CREATE DATABASE IF NOT EXISTS sbtest;
Query OK, 1 row affected, 1 warning (0.00 sec)
GreatSQL> CREATE DATABASE IF NOT EXISTS sbtest1;
Query OK, 1 row affected (0.05 sec)
# 授權
GreatSQL> GRANT ALL PRIVILEGES ON sbtest.* TO grantee@'%';
Query OK, 0 rows affected (0.02 sec)
2)、查看許可權
GreatSQL> show grants for grantee@localhost;
+---------------------------------------------+
| Grants for grantee@localhost |
+---------------------------------------------+
| GRANT USAGE ON *.* TO `grantee`@`localhost` |
+---------------------------------------------+
1 row in set (0.01 sec)
許可權列表沒有顯示 grantee@localhost
對 sbtest 庫的許可權,但實際 grantee@localhost
已經擁有 sbtest 庫下所有操作許可權
3)、grantee@localhost 登錄,執行操作
GreatSQL> show grants;
+---------------------------------------------+
| Grants for grantee@localhost |
+---------------------------------------------+
| GRANT USAGE ON *.* TO `grantee`@`localhost` |
+---------------------------------------------+
1 row in set (0.00 sec)
GreatSQL> create table sbtest.t1(id int primary key);
Query OK, 0 rows affected (0.04 sec)
GreatSQL> insert into sbtest.t1 select 1;
Query OK, 1 row affected (0.01 sec)
Records: 1 Duplicates: 0 Warnings: 0
4)、使用 SHOW EFFECTIVE GRANTS
查看許可權
GreatSQL> show effective grants;
+-------------------------------------------------------------+
| Effective grants for grantee@localhost |
+-------------------------------------------------------------+
| GRANT USAGE ON *.* TO `grantee`@`localhost` |
| GRANT ALL PRIVILEGES ON `sbtest`.* TO `grantee`@`localhost` |
+-------------------------------------------------------------+
2 rows in set (0.01 sec)
SHOW EFFECTIVE GRANTS
****顯示出擁有的同 user 用戶許可權
3.2、匿名用戶
匿名用戶請參考:https://dev.mysql.com/doc/refman/8.0/en/connection-access.html
1)、創建匿名用戶並授權
# 未指定host,預設為%
GreatSQL> CREATE USER '';
Query OK, 0 rows affected (0.04 sec)
GreatSQL> GRANT ALL ON sbtest1.* TO '';
Query OK, 0 rows affected (0.02 sec)
2)、查看許可權
GreatSQL> show grants for grantee@localhost;
+---------------------------------------------+
| Grants for grantee@localhost |
+---------------------------------------------+
| GRANT USAGE ON *.* TO `grantee`@`localhost` |
+---------------------------------------------+
1 row in set (0.01 sec)
許可權列表沒有顯示 grantee@localhost
對 sbtest1 庫的許可權,但實際 grantee@localhost
已經擁有 sbtest1 庫下所有操作許可權
3)、grantee@localhost 登錄,執行操作
GreatSQL> select user(), current_user();
+-------------------+-------------------+
| user() | current_user() |
+-------------------+-------------------+
| grantee@localhost | grantee@localhost |
+-------------------+-------------------+
1 row in set (0.00 sec)
GreatSQL> show grants;
+---------------------------------------------+
| Grants for grantee@localhost |
+---------------------------------------------+
| GRANT USAGE ON *.* TO `grantee`@`localhost` |
+---------------------------------------------+
1 row in set (0.00 sec)
GreatSQL> create table sbtest1.t2(id int primary key);
Query OK, 0 rows affected (0.03 sec)
GreatSQL> insert into sbtest1.t2 select 2;
Query OK, 1 row affected (0.01 sec)
Records: 1 Duplicates: 0 Warnings: 0
4)、使用 SHOW EFFECTIVE GRANTS
查看許可權
GreatSQL> show effective grants;
+-------------------------------------------------------------+
| Effective grants for grantee@localhost |
+-------------------------------------------------------------+
| GRANT USAGE ON *.* TO `grantee`@`localhost` |
| GRANT ALL PRIVILEGES ON `sbtest`.* TO `grantee`@`localhost` |
+-------------------------------------------------------------+
2 rows in set (0.01 sec)
註意:****SHOW EFFECTIVE GRANTS
沒有顯示出擁有的匿名用戶許可權,sbtest.*是擁有的同 user 用戶許可權
4、建議
1)、使用 SHOW EFFECTIVE GRANTS
代替 SHOW GRANTS
(GreatDB、GreatSQL、Percona Server)
GreatSQL> show effective grants for user1@`172.%`;
+-------------------------------------------------------+
| Effective grants for user1@172.% |
+-------------------------------------------------------+
| GRANT USAGE ON *.* TO `user1`@`172.%` |
| GRANT ALL PRIVILEGES ON `sbtest`.* TO `user1`@`172.%` |
+-------------------------------------------------------+
2 rows in set (0.00 sec)
2)、賬號加固
- 匿名用戶,禁止匿名用戶登錄
GreatSQL> select user, host from mysql.user where user='';
+------+------+
| user | host |
+------+------+
| | % |
+------+------+
1 row in set (0.02 sec)
- 同 user 不同 host
GreatSQL> select u.user, u.host, p.user priv_user, p.host priv_host from (
-> select user, host from mysql.db
-> union
-> select user, host from mysql.tables_priv
-> union
-> select user, host from mysql.columns_priv) p
-> left join mysql.user u on p.user=u.user
-> where p.host<>u.host;
+---------+-----------+-----------+-----------+
| user | host | priv_user | priv_host |
+---------+-----------+-----------+-----------+
| user1 | 172.% | user1 | % |
| grantee | localhost | grantee | % |
+---------+-----------+-----------+-----------+
2 rows in set (0.01 sec)
到各許可權表查看對應user信息,核實許可權'錯亂'的原因
GreatSQL> select * from mysql.user where user='user1'\G
*************************** 1. row ***************************
Host: 172.%
User: user1
Select_priv: N
...
1 row in set (0.05 sec)
GreatSQL> select * from mysql.db where user='user1'\G
*************************** 1. row ***************************
Host: %
Db: sbtest
User: user1
Select_priv: Y
...
1 row in set (0.01 sec)
user 表只有 user1@'172.%',db 表只有 user1@'%',對應算兩個用戶。
可能是手動更新過許可權表:例如創建用戶xx@'%',授權db.*所有許可權,後來更新mysql.user表中的記錄為xx@'172.%'限制登錄來源。
根據精確匹配原則,user1可以從172.%主機連接資料庫,全局許可權為N(mysql.user),db許可權匹配上user1@'%',擁有sbtest庫的所有操作許可權。
Enjoy GreatSQL