更新时间:2022-08-16 GMT+08:00

行级访问控制

行级访问控制特性将数据库访问控制精确到数据表行级别,使数据库达到行级访问控制的能力。不同用户执行相同的SQL查询操作,读取到的结果是不同的。

用户可以在数据表创建行访问控制(Row Level Security)策略,该策略是指针对特定数据库用户、特定SQL操作生效的表达式。当数据库用户对数据表访问时,若SQL满足数据表特定的Row Level Security策略,在查询优化阶段将满足条件的表达式,按照属性(PERMISSIVE | RESTRICTIVE)类型,通过AND或OR方式拼接,应用到执行计划上。

行级访问控制的目的是控制表中行级数据可见性,通过在数据表上预定义Filter,在查询优化阶段将满足条件的表达式应用到执行计划上,影响最终的执行结果。当前受影响的SQL语句包括SELECT,UPDATE,DELETE。

场景一:某表中汇总了不同用户的数据,但是不同用户只能查看自身相关的数据信息,不能查看其他用户的数据信息。

 1
 2
 3
 4
 5
 6
 7
 8
 9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
--创建用户alice, bob, peter
CREATE ROLE alice PASSWORD 'password';
CREATE ROLE bob PASSWORD 'password';
CREATE ROLE peter PASSWORD 'password';

--创建表public.all_data,包含不同用户数据信息
CREATE TABLE public.all_data(id int, role varchar(100), data varchar(100));

--向数据表插入数据
INSERT INTO all_data VALUES(1, 'alice', 'alice data');
INSERT INTO all_data VALUES(2, 'bob', 'bob data');
INSERT INTO all_data VALUES(3, 'peter', 'peter data');

--将表all_data的读取权限赋予alice,bob和peter用户
GRANT SELECT ON all_data TO alice, bob, peter;

--打开行访问控制策略开关
ALTER TABLE all_data ENABLE ROW LEVEL SECURITY;

--创建行访问控制策略,当前用户只能查看用户自身的数据
CREATE ROW LEVEL SECURITY POLICY all_data_rls ON all_data USING(role = CURRENT_USER);

--查看表详细信息
\d+ all_data
                               Table "public.all_data"
 Column |          Type          | Modifiers | Storage  | Stats target | Description
--------+------------------------+-----------+----------+--------------+-------------
 id     | integer                |           | plain    |              |
 role   | character varying(100) |           | extended |              |
 data   | character varying(100) |           | extended |              |
Row Level Security Policies:
    POLICY "all_data_rls"
      USING (((role)::name = "current_user"()))
Has OIDs: no
Distribute By: HASH(id)
Location Nodes: ALL DATANODES
Options: orientation=row, compression=no, enable_rowsecurity=true

--切换至用户alice,执行SQL"SELECT * FROM all_data"
SET ROLE alice PASSWORD 'password';
SELECT * FROM all_data;
 id | role  |    data
----+-------+------------
  1 | alice | alice data
(1 row)

EXPLAIN(COSTS OFF) SELECT * FROM all_data;
                           QUERY PLAN
----------------------------------------------------------------
  id |          operation
 ----+------------------------------
   1 | ->  Streaming (type: GATHER)
   2 |    ->  Seq Scan on all_data

         Predicate Information (identified by plan id)
 --------------------------------------------------------------
   2 --Seq Scan on all_data
         Filter: ((role)::name = 'alice'::name)
 Notice: This query is influenced by row level security feature
(10 rows)

--切换至用户peter,执行SQL"SELECT * FROM .all_data"
SET ROLE peter PASSWORD 'password';
SELECT * FROM all_data;
 id | role  |    data
----+-------+------------
  3 | peter | peter data
(1 row)

EXPLAIN(COSTS OFF) SELECT * FROM all_data;
                           QUERY PLAN
----------------------------------------------------------------
  id |          operation
 ----+------------------------------
   1 | ->  Streaming (type: GATHER)
   2 |    ->  Seq Scan on all_data

         Predicate Information (identified by plan id)
 --------------------------------------------------------------
   2 --Seq Scan on all_data
         Filter: ((role)::name = 'peter'::name)
 Notice: This query is influenced by row level security feature
(10 rows)