MySQL使用show?effective?grants查看權(quán)限官方解讀
1、問題描述
用戶 show grants
顯示只有連接權(quán)限,但該用戶卻能執(zhí)行 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 官方手冊(cè),有這樣一段話
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, but SHOW GRANTS does not display them.
Percona Server 官方手冊(cè),有類似一段話
https://docs.percona.com/percona-server/8.0/management/extend...
In Oracle MySQL SHOW 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, but SHOW GRANTS will not display them. Percona Server for MySQL offers the SHOW 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 范圍的子集
滿足上述兩個(gè)條件,此時(shí)用戶 B 擁有顯式授予給用戶 A 的權(quán)限,但 SHOW GRANTS 不會(huì)顯示這部分權(quán)限。在 Percona Server 可以通過 SHOW EFFECTIVE GRANTS
查看。
3、測(cè)試驗(yàn)證
3.1、同 user 用戶
1)、創(chuàng)建用戶并授權(quán)
# 創(chuàng)建用戶 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) # 創(chuàng)建數(shù)據(jù)庫 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) # 授權(quán) GreatSQL> GRANT ALL PRIVILEGES ON sbtest.* TO grantee@'%'; Query OK, 0 rows affected (0.02 sec)
2)、查看權(quán)限
GreatSQL> show grants for grantee@localhost; +---------------------------------------------+ | Grants for grantee@localhost | +---------------------------------------------+ | GRANT USAGE ON *.* TO `grantee`@`localhost` | +---------------------------------------------+ 1 row in set (0.01 sec)
權(quán)限列表沒有顯示 grantee@localhost
對(duì) sbtest 庫的權(quán)限,但實(shí)際 grantee@localhost
已經(jīng)擁有 sbtest 庫下所有操作權(quán)限
3)、grantee@localhost 登錄,執(zhí)行操作
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
查看權(quán)限
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 用戶權(quán)限
3.2、匿名用戶
匿名用戶請(qǐng)參考:https://dev.mysql.com/doc/refman/8.0/en/connection-access.html
1)、創(chuàng)建匿名用戶并授權(quán)
# 未指定host,默認(rèn)為% 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)、查看權(quán)限
GreatSQL> show grants for grantee@localhost; +---------------------------------------------+ | Grants for grantee@localhost | +---------------------------------------------+ | GRANT USAGE ON *.* TO `grantee`@`localhost` | +---------------------------------------------+ 1 row in set (0.01 sec)
權(quán)限列表沒有顯示 grantee@localhost
對(duì) sbtest1 庫的權(quán)限,但實(shí)際 grantee@localhost
已經(jīng)擁有 sbtest1 庫下所有操作權(quán)限
3)、grantee@localhost 登錄,執(zhí)行操作
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
查看權(quán)限
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
沒有顯示出擁有的匿名用戶權(quán)限,sbtest.*是擁有的同 user 用戶權(quán)限
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)、賬號(hào)加固
- 匿名用戶,禁止匿名用戶登錄
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)
到各權(quán)限表查看對(duì)應(yīng)user信息,核實(shí)權(quán)限'錯(cuò)亂'的原因
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@'%',對(duì)應(yīng)算兩個(gè)用戶。
可能是手動(dòng)更新過權(quán)限表:例如創(chuàng)建用戶xx@'%',授權(quán)db.*所有權(quán)限,后來更新mysql.user表中的記錄為xx@'172.%'限制登錄來源。
根據(jù)精確匹配原則,user1可以從172.%主機(jī)連接數(shù)據(jù)庫,全局權(quán)限為N(mysql.user),db權(quán)限匹配上user1@'%',擁有sbtest庫的所有操作權(quán)限。
Enjoy GreatSQL :)
## 關(guān)于 GreatSQL
GreatSQL是由萬里數(shù)據(jù)庫維護(hù)的MySQL分支,專注于提升MGR可靠性及性能,支持InnoDB并行查詢特性,是適用于金融級(jí)應(yīng)用的MySQL分支版本。
相關(guān)鏈接:
以上就是MySQL使用show effective grants查看權(quán)限的詳細(xì)內(nèi)容,更多關(guān)于MySQL show effective grants查看權(quán)限的資料請(qǐng)關(guān)注腳本之家其它相關(guān)文章!
- MySQL中SHOW TABLE STATUS的使用及說明
- MySQL通過show status查看、explain分析優(yōu)化數(shù)據(jù)庫性能
- MySQL通過show processlist命令檢視性能的講解
- MySQL中使用SHOW PROFILE命令分析性能的用法整理
- Oracle中實(shí)現(xiàn)MySQL show index from table命令SQL腳本分享
- mysql show processlist 顯示mysql查詢進(jìn)程
- MySQL中show命令方法得到表列及整個(gè)庫的詳細(xì)信息(精品珍藏)
- MySQL中的SHOW FULL PROCESSLIST命令實(shí)現(xiàn)
相關(guān)文章
Windows下MySQL8.0.11社區(qū)綠色版安裝步驟圖解
在本教程中使用MySQL最新的MySQL服務(wù)8.0.11的社區(qū)綠色版本進(jìn)行安裝,綠色版為zip格式的包,安裝步驟分為四大步驟,具體哪四大步驟大家跟隨腳本之家小編一起學(xué)習(xí)吧2018-05-05Mac OS系統(tǒng)下mysql 5.7.20安裝教程圖文詳解
這篇文章主要介紹了Mac OS系統(tǒng)下mysql 5.7.20安裝教程圖文詳解,本文給大家介紹的非常詳細(xì),具有參考借鑒價(jià)值,需要的朋友可以參考下2017-11-11MySQL中LIKE?BINARY和LIKE模糊查詢實(shí)例代碼
通常在實(shí)際應(yīng)用中,會(huì)涉及到模糊查詢的需求,下面這篇文章主要給大家介紹了關(guān)于MySQL中LIKE?BINARY和LIKE模糊查詢的相關(guān)資料,文中通過實(shí)例代碼介紹的非常詳細(xì),需要的朋友可以參考下2022-11-11MySQL橫縱表相互轉(zhuǎn)化操作實(shí)現(xiàn)方法
這篇文章主要介紹了MySQL橫縱表相互轉(zhuǎn)化操作,結(jié)合實(shí)例形式分析了MySQL橫縱表相互轉(zhuǎn)化操作基本原理、實(shí)現(xiàn)方法與相關(guān)注意事項(xiàng),需要的朋友可以參考下2020-06-06mysql簡(jiǎn)單實(shí)現(xiàn)查詢結(jié)果添加序列號(hào)的方法
這篇文章主要介紹了mysql簡(jiǎn)單實(shí)現(xiàn)查詢結(jié)果添加序列號(hào)的方法,結(jié)合實(shí)例形式演示了2種查詢結(jié)果添加序列號(hào)的技巧,具有一定參考借鑒價(jià)值,需要的朋友可以參考下2016-06-06mysql中提高Order by語句查詢效率的兩個(gè)思路分析
在MySQL數(shù)據(jù)庫中,Order by語句的使用頻率是比較高的。但是眾所周知,在使用這個(gè)語句時(shí),往往會(huì)降低數(shù)據(jù)查詢的性能。2011-03-03