使用Show Effective Grants查看权限

2023年 7月 26日 71.4k 0

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.htmlSHOW 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 官方手册,有类似一段话

https://docs.percona.com/percona-server/8.0/management/extended_show_grants.htmlIn 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 范围的子集

满足上述两个条件,此时用户 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.hostu.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库的所有操作权限。

相关文章

Oracle如何使用授予和撤销权限的语法和示例
Awesome Project: 探索 MatrixOrigin 云原生分布式数据库
下载丨66页PDF,云和恩墨技术通讯(2024年7月刊)
社区版oceanbase安装
Oracle 导出CSV工具-sqluldr2
ETL数据集成丨快速将MySQL数据迁移至Doris数据库

发布评论