1--
2-- Test of Row-level security feature
3--
4
5-- Clean up in case a prior regression run failed
6
7-- Suppress NOTICE messages when users/groups don't exist
8SET client_min_messages TO 'warning';
9
10DROP USER IF EXISTS regress_rls_alice;
11DROP USER IF EXISTS regress_rls_bob;
12DROP USER IF EXISTS regress_rls_carol;
13DROP USER IF EXISTS regress_rls_dave;
14DROP USER IF EXISTS regress_rls_exempt_user;
15DROP ROLE IF EXISTS regress_rls_group1;
16DROP ROLE IF EXISTS regress_rls_group2;
17
18DROP SCHEMA IF EXISTS regress_rls_schema CASCADE;
19
20RESET client_min_messages;
21
22-- initial setup
23CREATE USER regress_rls_alice NOLOGIN;
24CREATE USER regress_rls_bob NOLOGIN;
25CREATE USER regress_rls_carol NOLOGIN;
26CREATE USER regress_rls_dave NOLOGIN;
27CREATE USER regress_rls_exempt_user BYPASSRLS NOLOGIN;
28CREATE ROLE regress_rls_group1 NOLOGIN;
29CREATE ROLE regress_rls_group2 NOLOGIN;
30
31GRANT regress_rls_group1 TO regress_rls_bob;
32GRANT regress_rls_group2 TO regress_rls_carol;
33
34CREATE SCHEMA regress_rls_schema;
35GRANT ALL ON SCHEMA regress_rls_schema to public;
36SET search_path = regress_rls_schema;
37
38-- setup of malicious function
39CREATE OR REPLACE FUNCTION f_leak(text) RETURNS bool
40    COST 0.0000001 LANGUAGE plpgsql
41    AS 'BEGIN RAISE NOTICE ''f_leak => %'', $1; RETURN true; END';
42GRANT EXECUTE ON FUNCTION f_leak(text) TO public;
43
44-- BASIC Row-Level Security Scenario
45
46SET SESSION AUTHORIZATION regress_rls_alice;
47CREATE TABLE uaccount (
48    pguser      name primary key,
49    seclv       int
50);
51GRANT SELECT ON uaccount TO public;
52INSERT INTO uaccount VALUES
53    ('regress_rls_alice', 99),
54    ('regress_rls_bob', 1),
55    ('regress_rls_carol', 2),
56    ('regress_rls_dave', 3);
57
58CREATE TABLE category (
59    cid        int primary key,
60    cname      text
61);
62GRANT ALL ON category TO public;
63INSERT INTO category VALUES
64    (11, 'novel'),
65    (22, 'science fiction'),
66    (33, 'technology'),
67    (44, 'manga');
68
69CREATE TABLE document (
70    did         int primary key,
71    cid         int references category(cid),
72    dlevel      int not null,
73    dauthor     name,
74    dtitle      text
75);
76GRANT ALL ON document TO public;
77INSERT INTO document VALUES
78    ( 1, 11, 1, 'regress_rls_bob', 'my first novel'),
79    ( 2, 11, 2, 'regress_rls_bob', 'my second novel'),
80    ( 3, 22, 2, 'regress_rls_bob', 'my science fiction'),
81    ( 4, 44, 1, 'regress_rls_bob', 'my first manga'),
82    ( 5, 44, 2, 'regress_rls_bob', 'my second manga'),
83    ( 6, 22, 1, 'regress_rls_carol', 'great science fiction'),
84    ( 7, 33, 2, 'regress_rls_carol', 'great technology book'),
85    ( 8, 44, 1, 'regress_rls_carol', 'great manga'),
86    ( 9, 22, 1, 'regress_rls_dave', 'awesome science fiction'),
87    (10, 33, 2, 'regress_rls_dave', 'awesome technology book');
88
89ALTER TABLE document ENABLE ROW LEVEL SECURITY;
90
91-- user's security level must be higher than or equal to document's
92CREATE POLICY p1 ON document AS PERMISSIVE
93    USING (dlevel <= (SELECT seclv FROM uaccount WHERE pguser = current_user));
94
95-- try to create a policy of bogus type
96CREATE POLICY p1 ON document AS UGLY
97    USING (dlevel <= (SELECT seclv FROM uaccount WHERE pguser = current_user));
98
99-- but Dave isn't allowed to anything at cid 50 or above
100-- this is to make sure that we sort the policies by name first
101-- when applying WITH CHECK, a later INSERT by Dave should fail due
102-- to p1r first
103CREATE POLICY p2r ON document AS RESTRICTIVE TO regress_rls_dave
104    USING (cid <> 44 AND cid < 50);
105
106-- and Dave isn't allowed to see manga documents
107CREATE POLICY p1r ON document AS RESTRICTIVE TO regress_rls_dave
108    USING (cid <> 44);
109
110\dp
111\d document
112SELECT * FROM pg_policies WHERE schemaname = 'regress_rls_schema' AND tablename = 'document' ORDER BY policyname;
113
114-- viewpoint from regress_rls_bob
115SET SESSION AUTHORIZATION regress_rls_bob;
116SET row_security TO ON;
117SELECT * FROM document WHERE f_leak(dtitle) ORDER BY did;
118SELECT * FROM document NATURAL JOIN category WHERE f_leak(dtitle) ORDER BY did;
119
120-- try a sampled version
121SELECT * FROM document TABLESAMPLE BERNOULLI(50) REPEATABLE(0)
122  WHERE f_leak(dtitle) ORDER BY did;
123
124-- viewpoint from regress_rls_carol
125SET SESSION AUTHORIZATION regress_rls_carol;
126SELECT * FROM document WHERE f_leak(dtitle) ORDER BY did;
127SELECT * FROM document NATURAL JOIN category WHERE f_leak(dtitle) ORDER BY did;
128
129-- try a sampled version
130SELECT * FROM document TABLESAMPLE BERNOULLI(50) REPEATABLE(0)
131  WHERE f_leak(dtitle) ORDER BY did;
132
133EXPLAIN (COSTS OFF) SELECT * FROM document WHERE f_leak(dtitle);
134EXPLAIN (COSTS OFF) SELECT * FROM document NATURAL JOIN category WHERE f_leak(dtitle);
135
136-- viewpoint from regress_rls_dave
137SET SESSION AUTHORIZATION regress_rls_dave;
138SELECT * FROM document WHERE f_leak(dtitle) ORDER BY did;
139SELECT * FROM document NATURAL JOIN category WHERE f_leak(dtitle) ORDER BY did;
140
141EXPLAIN (COSTS OFF) SELECT * FROM document WHERE f_leak(dtitle);
142EXPLAIN (COSTS OFF) SELECT * FROM document NATURAL JOIN category WHERE f_leak(dtitle);
143
144-- 44 would technically fail for both p2r and p1r, but we should get an error
145-- back from p1r for this because it sorts first
146INSERT INTO document VALUES (100, 44, 1, 'regress_rls_dave', 'testing sorting of policies'); -- fail
147-- Just to see a p2r error
148INSERT INTO document VALUES (100, 55, 1, 'regress_rls_dave', 'testing sorting of policies'); -- fail
149
150-- only owner can change policies
151ALTER POLICY p1 ON document USING (true);    --fail
152DROP POLICY p1 ON document;                  --fail
153
154SET SESSION AUTHORIZATION regress_rls_alice;
155ALTER POLICY p1 ON document USING (dauthor = current_user);
156
157-- viewpoint from regress_rls_bob again
158SET SESSION AUTHORIZATION regress_rls_bob;
159SELECT * FROM document WHERE f_leak(dtitle) ORDER BY did;
160SELECT * FROM document NATURAL JOIN category WHERE f_leak(dtitle) ORDER by did;
161
162-- viewpoint from rls_regres_carol again
163SET SESSION AUTHORIZATION regress_rls_carol;
164SELECT * FROM document WHERE f_leak(dtitle) ORDER BY did;
165SELECT * FROM document NATURAL JOIN category WHERE f_leak(dtitle) ORDER by did;
166
167EXPLAIN (COSTS OFF) SELECT * FROM document WHERE f_leak(dtitle);
168EXPLAIN (COSTS OFF) SELECT * FROM document NATURAL JOIN category WHERE f_leak(dtitle);
169
170-- interaction of FK/PK constraints
171SET SESSION AUTHORIZATION regress_rls_alice;
172CREATE POLICY p2 ON category
173    USING (CASE WHEN current_user = 'regress_rls_bob' THEN cid IN (11, 33)
174           WHEN current_user = 'regress_rls_carol' THEN cid IN (22, 44)
175           ELSE false END);
176
177ALTER TABLE category ENABLE ROW LEVEL SECURITY;
178
179-- cannot delete PK referenced by invisible FK
180SET SESSION AUTHORIZATION regress_rls_bob;
181SELECT * FROM document d FULL OUTER JOIN category c on d.cid = c.cid ORDER BY d.did, c.cid;
182DELETE FROM category WHERE cid = 33;    -- fails with FK violation
183
184-- can insert FK referencing invisible PK
185SET SESSION AUTHORIZATION regress_rls_carol;
186SELECT * FROM document d FULL OUTER JOIN category c on d.cid = c.cid ORDER BY d.did, c.cid;
187INSERT INTO document VALUES (11, 33, 1, current_user, 'hoge');
188
189-- UNIQUE or PRIMARY KEY constraint violation DOES reveal presence of row
190SET SESSION AUTHORIZATION regress_rls_bob;
191INSERT INTO document VALUES (8, 44, 1, 'regress_rls_bob', 'my third manga'); -- Must fail with unique violation, revealing presence of did we can't see
192SELECT * FROM document WHERE did = 8; -- and confirm we can't see it
193
194-- RLS policies are checked before constraints
195INSERT INTO document VALUES (8, 44, 1, 'regress_rls_carol', 'my third manga'); -- Should fail with RLS check violation, not duplicate key violation
196UPDATE document SET did = 8, dauthor = 'regress_rls_carol' WHERE did = 5; -- Should fail with RLS check violation, not duplicate key violation
197
198-- database superuser does bypass RLS policy when enabled
199RESET SESSION AUTHORIZATION;
200SET row_security TO ON;
201SELECT * FROM document;
202SELECT * FROM category;
203
204-- database superuser does bypass RLS policy when disabled
205RESET SESSION AUTHORIZATION;
206SET row_security TO OFF;
207SELECT * FROM document;
208SELECT * FROM category;
209
210-- database non-superuser with bypass privilege can bypass RLS policy when disabled
211SET SESSION AUTHORIZATION regress_rls_exempt_user;
212SET row_security TO OFF;
213SELECT * FROM document;
214SELECT * FROM category;
215
216-- RLS policy does not apply to table owner when RLS enabled.
217SET SESSION AUTHORIZATION regress_rls_alice;
218SET row_security TO ON;
219SELECT * FROM document;
220SELECT * FROM category;
221
222-- RLS policy does not apply to table owner when RLS disabled.
223SET SESSION AUTHORIZATION regress_rls_alice;
224SET row_security TO OFF;
225SELECT * FROM document;
226SELECT * FROM category;
227
228--
229-- Table inheritance and RLS policy
230--
231SET SESSION AUTHORIZATION regress_rls_alice;
232
233SET row_security TO ON;
234
235CREATE TABLE t1 (id int not null primary key, a int, junk1 text, b text);
236ALTER TABLE t1 DROP COLUMN junk1;    -- just a disturbing factor
237GRANT ALL ON t1 TO public;
238
239COPY t1 FROM stdin WITH ;
240101	1	aba
241102	2	bbb
242103	3	ccc
243104	4	dad
244\.
245
246CREATE TABLE t2 (c float) INHERITS (t1);
247GRANT ALL ON t2 TO public;
248
249COPY t2 FROM stdin;
250201	1	abc	1.1
251202	2	bcd	2.2
252203	3	cde	3.3
253204	4	def	4.4
254\.
255
256CREATE TABLE t3 (id int not null primary key, c text, b text, a int);
257ALTER TABLE t3 INHERIT t1;
258GRANT ALL ON t3 TO public;
259
260COPY t3(id, a,b,c) FROM stdin;
261301	1	xxx	X
262302	2	yyy	Y
263303	3	zzz	Z
264\.
265
266CREATE POLICY p1 ON t1 FOR ALL TO PUBLIC USING (a % 2 = 0); -- be even number
267CREATE POLICY p2 ON t2 FOR ALL TO PUBLIC USING (a % 2 = 1); -- be odd number
268
269ALTER TABLE t1 ENABLE ROW LEVEL SECURITY;
270ALTER TABLE t2 ENABLE ROW LEVEL SECURITY;
271
272SET SESSION AUTHORIZATION regress_rls_bob;
273
274SELECT * FROM t1;
275EXPLAIN (COSTS OFF) SELECT * FROM t1;
276
277SELECT * FROM t1 WHERE f_leak(b);
278EXPLAIN (COSTS OFF) SELECT * FROM t1 WHERE f_leak(b);
279
280-- reference to system column
281SELECT tableoid::regclass, * FROM t1;
282EXPLAIN (COSTS OFF) SELECT *, t1 FROM t1;
283
284-- reference to whole-row reference
285SELECT *, t1 FROM t1;
286EXPLAIN (COSTS OFF) SELECT *, t1 FROM t1;
287
288-- for share/update lock
289SELECT * FROM t1 FOR SHARE;
290EXPLAIN (COSTS OFF) SELECT * FROM t1 FOR SHARE;
291
292SELECT * FROM t1 WHERE f_leak(b) FOR SHARE;
293EXPLAIN (COSTS OFF) SELECT * FROM t1 WHERE f_leak(b) FOR SHARE;
294
295-- union all query
296SELECT a, b, tableoid::regclass FROM t2 UNION ALL SELECT a, b, tableoid::regclass FROM t3;
297EXPLAIN (COSTS OFF) SELECT a, b, tableoid::regclass FROM t2 UNION ALL SELECT a, b, tableoid::regclass FROM t3;
298
299-- superuser is allowed to bypass RLS checks
300RESET SESSION AUTHORIZATION;
301SET row_security TO OFF;
302SELECT * FROM t1 WHERE f_leak(b);
303EXPLAIN (COSTS OFF) SELECT * FROM t1 WHERE f_leak(b);
304
305-- non-superuser with bypass privilege can bypass RLS policy when disabled
306SET SESSION AUTHORIZATION regress_rls_exempt_user;
307SET row_security TO OFF;
308SELECT * FROM t1 WHERE f_leak(b);
309EXPLAIN (COSTS OFF) SELECT * FROM t1 WHERE f_leak(b);
310
311--
312-- Partitioned Tables
313--
314
315SET SESSION AUTHORIZATION regress_rls_alice;
316
317CREATE TABLE part_document (
318    did         int,
319    cid         int,
320    dlevel      int not null,
321    dauthor     name,
322    dtitle      text
323) PARTITION BY RANGE (cid);
324GRANT ALL ON part_document TO public;
325
326-- Create partitions for document categories
327CREATE TABLE part_document_fiction PARTITION OF part_document FOR VALUES FROM (11) to (12);
328CREATE TABLE part_document_satire PARTITION OF part_document FOR VALUES FROM (55) to (56);
329CREATE TABLE part_document_nonfiction PARTITION OF part_document FOR VALUES FROM (99) to (100);
330
331GRANT ALL ON part_document_fiction TO public;
332GRANT ALL ON part_document_satire TO public;
333GRANT ALL ON part_document_nonfiction TO public;
334
335INSERT INTO part_document VALUES
336    ( 1, 11, 1, 'regress_rls_bob', 'my first novel'),
337    ( 2, 11, 2, 'regress_rls_bob', 'my second novel'),
338    ( 3, 99, 2, 'regress_rls_bob', 'my science textbook'),
339    ( 4, 55, 1, 'regress_rls_bob', 'my first satire'),
340    ( 5, 99, 2, 'regress_rls_bob', 'my history book'),
341    ( 6, 11, 1, 'regress_rls_carol', 'great science fiction'),
342    ( 7, 99, 2, 'regress_rls_carol', 'great technology book'),
343    ( 8, 55, 2, 'regress_rls_carol', 'great satire'),
344    ( 9, 11, 1, 'regress_rls_dave', 'awesome science fiction'),
345    (10, 99, 2, 'regress_rls_dave', 'awesome technology book');
346
347ALTER TABLE part_document ENABLE ROW LEVEL SECURITY;
348
349-- Create policy on parent
350-- user's security level must be higher than or equal to document's
351CREATE POLICY pp1 ON part_document AS PERMISSIVE
352    USING (dlevel <= (SELECT seclv FROM uaccount WHERE pguser = current_user));
353
354-- Dave is only allowed to see cid < 55
355CREATE POLICY pp1r ON part_document AS RESTRICTIVE TO regress_rls_dave
356    USING (cid < 55);
357
358\d+ part_document
359SELECT * FROM pg_policies WHERE schemaname = 'regress_rls_schema' AND tablename like '%part_document%' ORDER BY policyname;
360
361-- viewpoint from regress_rls_bob
362SET SESSION AUTHORIZATION regress_rls_bob;
363SET row_security TO ON;
364SELECT * FROM part_document WHERE f_leak(dtitle) ORDER BY did;
365EXPLAIN (COSTS OFF) SELECT * FROM part_document WHERE f_leak(dtitle);
366
367-- viewpoint from regress_rls_carol
368SET SESSION AUTHORIZATION regress_rls_carol;
369SELECT * FROM part_document WHERE f_leak(dtitle) ORDER BY did;
370EXPLAIN (COSTS OFF) SELECT * FROM part_document WHERE f_leak(dtitle);
371
372-- viewpoint from regress_rls_dave
373SET SESSION AUTHORIZATION regress_rls_dave;
374SELECT * FROM part_document WHERE f_leak(dtitle) ORDER BY did;
375EXPLAIN (COSTS OFF) SELECT * FROM part_document WHERE f_leak(dtitle);
376
377-- pp1 ERROR
378INSERT INTO part_document VALUES (100, 11, 5, 'regress_rls_dave', 'testing pp1'); -- fail
379-- pp1r ERROR
380INSERT INTO part_document VALUES (100, 99, 1, 'regress_rls_dave', 'testing pp1r'); -- fail
381
382-- Show that RLS policy does not apply for direct inserts to children
383-- This should fail with RLS POLICY pp1r violation.
384INSERT INTO part_document VALUES (100, 55, 1, 'regress_rls_dave', 'testing RLS with partitions'); -- fail
385-- But this should succeed.
386INSERT INTO part_document_satire VALUES (100, 55, 1, 'regress_rls_dave', 'testing RLS with partitions'); -- success
387-- We still cannot see the row using the parent
388SELECT * FROM part_document WHERE f_leak(dtitle) ORDER BY did;
389-- But we can if we look directly
390SELECT * FROM part_document_satire WHERE f_leak(dtitle) ORDER BY did;
391
392-- Turn on RLS and create policy on child to show RLS is checked before constraints
393SET SESSION AUTHORIZATION regress_rls_alice;
394ALTER TABLE part_document_satire ENABLE ROW LEVEL SECURITY;
395CREATE POLICY pp3 ON part_document_satire AS RESTRICTIVE
396    USING (cid < 55);
397-- This should fail with RLS violation now.
398SET SESSION AUTHORIZATION regress_rls_dave;
399INSERT INTO part_document_satire VALUES (101, 55, 1, 'regress_rls_dave', 'testing RLS with partitions'); -- fail
400-- And now we cannot see directly into the partition either, due to RLS
401SELECT * FROM part_document_satire WHERE f_leak(dtitle) ORDER BY did;
402-- The parent looks same as before
403-- viewpoint from regress_rls_dave
404SELECT * FROM part_document WHERE f_leak(dtitle) ORDER BY did;
405EXPLAIN (COSTS OFF) SELECT * FROM part_document WHERE f_leak(dtitle);
406
407-- viewpoint from regress_rls_carol
408SET SESSION AUTHORIZATION regress_rls_carol;
409SELECT * FROM part_document WHERE f_leak(dtitle) ORDER BY did;
410EXPLAIN (COSTS OFF) SELECT * FROM part_document WHERE f_leak(dtitle);
411
412-- only owner can change policies
413ALTER POLICY pp1 ON part_document USING (true);    --fail
414DROP POLICY pp1 ON part_document;                  --fail
415
416SET SESSION AUTHORIZATION regress_rls_alice;
417ALTER POLICY pp1 ON part_document USING (dauthor = current_user);
418
419-- viewpoint from regress_rls_bob again
420SET SESSION AUTHORIZATION regress_rls_bob;
421SELECT * FROM part_document WHERE f_leak(dtitle) ORDER BY did;
422
423-- viewpoint from rls_regres_carol again
424SET SESSION AUTHORIZATION regress_rls_carol;
425SELECT * FROM part_document WHERE f_leak(dtitle) ORDER BY did;
426
427EXPLAIN (COSTS OFF) SELECT * FROM part_document WHERE f_leak(dtitle);
428
429-- database superuser does bypass RLS policy when enabled
430RESET SESSION AUTHORIZATION;
431SET row_security TO ON;
432SELECT * FROM part_document ORDER BY did;
433SELECT * FROM part_document_satire ORDER by did;
434
435-- database non-superuser with bypass privilege can bypass RLS policy when disabled
436SET SESSION AUTHORIZATION regress_rls_exempt_user;
437SET row_security TO OFF;
438SELECT * FROM part_document ORDER BY did;
439SELECT * FROM part_document_satire ORDER by did;
440
441-- RLS policy does not apply to table owner when RLS enabled.
442SET SESSION AUTHORIZATION regress_rls_alice;
443SET row_security TO ON;
444SELECT * FROM part_document ORDER by did;
445SELECT * FROM part_document_satire ORDER by did;
446
447-- When RLS disabled, other users get ERROR.
448SET SESSION AUTHORIZATION regress_rls_dave;
449SET row_security TO OFF;
450SELECT * FROM part_document ORDER by did;
451SELECT * FROM part_document_satire ORDER by did;
452
453-- Check behavior with a policy that uses a SubPlan not an InitPlan.
454SET SESSION AUTHORIZATION regress_rls_alice;
455SET row_security TO ON;
456CREATE POLICY pp3 ON part_document AS RESTRICTIVE
457    USING ((SELECT dlevel <= seclv FROM uaccount WHERE pguser = current_user));
458
459SET SESSION AUTHORIZATION regress_rls_carol;
460INSERT INTO part_document VALUES (100, 11, 5, 'regress_rls_carol', 'testing pp3'); -- fail
461
462----- Dependencies -----
463SET SESSION AUTHORIZATION regress_rls_alice;
464SET row_security TO ON;
465
466CREATE TABLE dependee (x integer, y integer);
467
468CREATE TABLE dependent (x integer, y integer);
469CREATE POLICY d1 ON dependent FOR ALL
470    TO PUBLIC
471    USING (x = (SELECT d.x FROM dependee d WHERE d.y = y));
472
473DROP TABLE dependee; -- Should fail without CASCADE due to dependency on row security qual?
474
475DROP TABLE dependee CASCADE;
476
477EXPLAIN (COSTS OFF) SELECT * FROM dependent; -- After drop, should be unqualified
478
479-----   RECURSION    ----
480
481--
482-- Simple recursion
483--
484SET SESSION AUTHORIZATION regress_rls_alice;
485CREATE TABLE rec1 (x integer, y integer);
486CREATE POLICY r1 ON rec1 USING (x = (SELECT r.x FROM rec1 r WHERE y = r.y));
487ALTER TABLE rec1 ENABLE ROW LEVEL SECURITY;
488SET SESSION AUTHORIZATION regress_rls_bob;
489SELECT * FROM rec1; -- fail, direct recursion
490
491--
492-- Mutual recursion
493--
494SET SESSION AUTHORIZATION regress_rls_alice;
495CREATE TABLE rec2 (a integer, b integer);
496ALTER POLICY r1 ON rec1 USING (x = (SELECT a FROM rec2 WHERE b = y));
497CREATE POLICY r2 ON rec2 USING (a = (SELECT x FROM rec1 WHERE y = b));
498ALTER TABLE rec2 ENABLE ROW LEVEL SECURITY;
499
500SET SESSION AUTHORIZATION regress_rls_bob;
501SELECT * FROM rec1;    -- fail, mutual recursion
502
503--
504-- Mutual recursion via views
505--
506SET SESSION AUTHORIZATION regress_rls_bob;
507CREATE VIEW rec1v AS SELECT * FROM rec1;
508CREATE VIEW rec2v AS SELECT * FROM rec2;
509SET SESSION AUTHORIZATION regress_rls_alice;
510ALTER POLICY r1 ON rec1 USING (x = (SELECT a FROM rec2v WHERE b = y));
511ALTER POLICY r2 ON rec2 USING (a = (SELECT x FROM rec1v WHERE y = b));
512
513SET SESSION AUTHORIZATION regress_rls_bob;
514SELECT * FROM rec1;    -- fail, mutual recursion via views
515
516--
517-- Mutual recursion via .s.b views
518--
519SET SESSION AUTHORIZATION regress_rls_bob;
520
521DROP VIEW rec1v, rec2v CASCADE;
522
523CREATE VIEW rec1v WITH (security_barrier) AS SELECT * FROM rec1;
524CREATE VIEW rec2v WITH (security_barrier) AS SELECT * FROM rec2;
525SET SESSION AUTHORIZATION regress_rls_alice;
526CREATE POLICY r1 ON rec1 USING (x = (SELECT a FROM rec2v WHERE b = y));
527CREATE POLICY r2 ON rec2 USING (a = (SELECT x FROM rec1v WHERE y = b));
528
529SET SESSION AUTHORIZATION regress_rls_bob;
530SELECT * FROM rec1;    -- fail, mutual recursion via s.b. views
531
532--
533-- recursive RLS and VIEWs in policy
534--
535SET SESSION AUTHORIZATION regress_rls_alice;
536CREATE TABLE s1 (a int, b text);
537INSERT INTO s1 (SELECT x, md5(x::text) FROM generate_series(-10,10) x);
538
539CREATE TABLE s2 (x int, y text);
540INSERT INTO s2 (SELECT x, md5(x::text) FROM generate_series(-6,6) x);
541
542GRANT SELECT ON s1, s2 TO regress_rls_bob;
543
544CREATE POLICY p1 ON s1 USING (a in (select x from s2 where y like '%2f%'));
545CREATE POLICY p2 ON s2 USING (x in (select a from s1 where b like '%22%'));
546CREATE POLICY p3 ON s1 FOR INSERT WITH CHECK (a = (SELECT a FROM s1));
547
548ALTER TABLE s1 ENABLE ROW LEVEL SECURITY;
549ALTER TABLE s2 ENABLE ROW LEVEL SECURITY;
550
551SET SESSION AUTHORIZATION regress_rls_bob;
552CREATE VIEW v2 AS SELECT * FROM s2 WHERE y like '%af%';
553SELECT * FROM s1 WHERE f_leak(b); -- fail (infinite recursion)
554
555INSERT INTO s1 VALUES (1, 'foo'); -- fail (infinite recursion)
556
557SET SESSION AUTHORIZATION regress_rls_alice;
558DROP POLICY p3 on s1;
559ALTER POLICY p2 ON s2 USING (x % 2 = 0);
560
561SET SESSION AUTHORIZATION regress_rls_bob;
562SELECT * FROM s1 WHERE f_leak(b);	-- OK
563EXPLAIN (COSTS OFF) SELECT * FROM only s1 WHERE f_leak(b);
564
565SET SESSION AUTHORIZATION regress_rls_alice;
566ALTER POLICY p1 ON s1 USING (a in (select x from v2)); -- using VIEW in RLS policy
567SET SESSION AUTHORIZATION regress_rls_bob;
568SELECT * FROM s1 WHERE f_leak(b);	-- OK
569EXPLAIN (COSTS OFF) SELECT * FROM s1 WHERE f_leak(b);
570
571SELECT (SELECT x FROM s1 LIMIT 1) xx, * FROM s2 WHERE y like '%28%';
572EXPLAIN (COSTS OFF) SELECT (SELECT x FROM s1 LIMIT 1) xx, * FROM s2 WHERE y like '%28%';
573
574SET SESSION AUTHORIZATION regress_rls_alice;
575ALTER POLICY p2 ON s2 USING (x in (select a from s1 where b like '%d2%'));
576SET SESSION AUTHORIZATION regress_rls_bob;
577SELECT * FROM s1 WHERE f_leak(b);	-- fail (infinite recursion via view)
578
579-- prepared statement with regress_rls_alice privilege
580PREPARE p1(int) AS SELECT * FROM t1 WHERE a <= $1;
581EXECUTE p1(2);
582EXPLAIN (COSTS OFF) EXECUTE p1(2);
583
584-- superuser is allowed to bypass RLS checks
585RESET SESSION AUTHORIZATION;
586SET row_security TO OFF;
587SELECT * FROM t1 WHERE f_leak(b);
588EXPLAIN (COSTS OFF) SELECT * FROM t1 WHERE f_leak(b);
589
590-- plan cache should be invalidated
591EXECUTE p1(2);
592EXPLAIN (COSTS OFF) EXECUTE p1(2);
593
594PREPARE p2(int) AS SELECT * FROM t1 WHERE a = $1;
595EXECUTE p2(2);
596EXPLAIN (COSTS OFF) EXECUTE p2(2);
597
598-- also, case when privilege switch from superuser
599SET SESSION AUTHORIZATION regress_rls_bob;
600SET row_security TO ON;
601EXECUTE p2(2);
602EXPLAIN (COSTS OFF) EXECUTE p2(2);
603
604--
605-- UPDATE / DELETE and Row-level security
606--
607SET SESSION AUTHORIZATION regress_rls_bob;
608EXPLAIN (COSTS OFF) UPDATE t1 SET b = b || b WHERE f_leak(b);
609UPDATE t1 SET b = b || b WHERE f_leak(b);
610
611EXPLAIN (COSTS OFF) UPDATE only t1 SET b = b || '_updt' WHERE f_leak(b);
612UPDATE only t1 SET b = b || '_updt' WHERE f_leak(b);
613
614-- returning clause with system column
615UPDATE only t1 SET b = b WHERE f_leak(b) RETURNING tableoid::regclass, *, t1;
616UPDATE t1 SET b = b WHERE f_leak(b) RETURNING *;
617UPDATE t1 SET b = b WHERE f_leak(b) RETURNING tableoid::regclass, *, t1;
618
619-- updates with from clause
620EXPLAIN (COSTS OFF) UPDATE t2 SET b=t2.b FROM t3
621WHERE t2.a = 3 and t3.a = 2 AND f_leak(t2.b) AND f_leak(t3.b);
622
623UPDATE t2 SET b=t2.b FROM t3
624WHERE t2.a = 3 and t3.a = 2 AND f_leak(t2.b) AND f_leak(t3.b);
625
626EXPLAIN (COSTS OFF) UPDATE t1 SET b=t1.b FROM t2
627WHERE t1.a = 3 and t2.a = 3 AND f_leak(t1.b) AND f_leak(t2.b);
628
629UPDATE t1 SET b=t1.b FROM t2
630WHERE t1.a = 3 and t2.a = 3 AND f_leak(t1.b) AND f_leak(t2.b);
631
632EXPLAIN (COSTS OFF) UPDATE t2 SET b=t2.b FROM t1
633WHERE t1.a = 3 and t2.a = 3 AND f_leak(t1.b) AND f_leak(t2.b);
634
635UPDATE t2 SET b=t2.b FROM t1
636WHERE t1.a = 3 and t2.a = 3 AND f_leak(t1.b) AND f_leak(t2.b);
637
638-- updates with from clause self join
639EXPLAIN (COSTS OFF) UPDATE t2 t2_1 SET b = t2_2.b FROM t2 t2_2
640WHERE t2_1.a = 3 AND t2_2.a = t2_1.a AND t2_2.b = t2_1.b
641AND f_leak(t2_1.b) AND f_leak(t2_2.b) RETURNING *, t2_1, t2_2;
642
643UPDATE t2 t2_1 SET b = t2_2.b FROM t2 t2_2
644WHERE t2_1.a = 3 AND t2_2.a = t2_1.a AND t2_2.b = t2_1.b
645AND f_leak(t2_1.b) AND f_leak(t2_2.b) RETURNING *, t2_1, t2_2;
646
647EXPLAIN (COSTS OFF) UPDATE t1 t1_1 SET b = t1_2.b FROM t1 t1_2
648WHERE t1_1.a = 4 AND t1_2.a = t1_1.a AND t1_2.b = t1_1.b
649AND f_leak(t1_1.b) AND f_leak(t1_2.b) RETURNING *, t1_1, t1_2;
650
651UPDATE t1 t1_1 SET b = t1_2.b FROM t1 t1_2
652WHERE t1_1.a = 4 AND t1_2.a = t1_1.a AND t1_2.b = t1_1.b
653AND f_leak(t1_1.b) AND f_leak(t1_2.b) RETURNING *, t1_1, t1_2;
654
655RESET SESSION AUTHORIZATION;
656SET row_security TO OFF;
657SELECT * FROM t1 ORDER BY a,b;
658
659SET SESSION AUTHORIZATION regress_rls_bob;
660SET row_security TO ON;
661EXPLAIN (COSTS OFF) DELETE FROM only t1 WHERE f_leak(b);
662EXPLAIN (COSTS OFF) DELETE FROM t1 WHERE f_leak(b);
663
664DELETE FROM only t1 WHERE f_leak(b) RETURNING tableoid::regclass, *, t1;
665DELETE FROM t1 WHERE f_leak(b) RETURNING tableoid::regclass, *, t1;
666
667--
668-- S.b. view on top of Row-level security
669--
670SET SESSION AUTHORIZATION regress_rls_alice;
671CREATE TABLE b1 (a int, b text);
672INSERT INTO b1 (SELECT x, md5(x::text) FROM generate_series(-10,10) x);
673
674CREATE POLICY p1 ON b1 USING (a % 2 = 0);
675ALTER TABLE b1 ENABLE ROW LEVEL SECURITY;
676GRANT ALL ON b1 TO regress_rls_bob;
677
678SET SESSION AUTHORIZATION regress_rls_bob;
679CREATE VIEW bv1 WITH (security_barrier) AS SELECT * FROM b1 WHERE a > 0 WITH CHECK OPTION;
680GRANT ALL ON bv1 TO regress_rls_carol;
681
682SET SESSION AUTHORIZATION regress_rls_carol;
683
684EXPLAIN (COSTS OFF) SELECT * FROM bv1 WHERE f_leak(b);
685SELECT * FROM bv1 WHERE f_leak(b);
686
687INSERT INTO bv1 VALUES (-1, 'xxx'); -- should fail view WCO
688INSERT INTO bv1 VALUES (11, 'xxx'); -- should fail RLS check
689INSERT INTO bv1 VALUES (12, 'xxx'); -- ok
690
691EXPLAIN (COSTS OFF) UPDATE bv1 SET b = 'yyy' WHERE a = 4 AND f_leak(b);
692UPDATE bv1 SET b = 'yyy' WHERE a = 4 AND f_leak(b);
693
694EXPLAIN (COSTS OFF) DELETE FROM bv1 WHERE a = 6 AND f_leak(b);
695DELETE FROM bv1 WHERE a = 6 AND f_leak(b);
696
697SET SESSION AUTHORIZATION regress_rls_alice;
698SELECT * FROM b1;
699--
700-- INSERT ... ON CONFLICT DO UPDATE and Row-level security
701--
702
703SET SESSION AUTHORIZATION regress_rls_alice;
704DROP POLICY p1 ON document;
705DROP POLICY p1r ON document;
706
707CREATE POLICY p1 ON document FOR SELECT USING (true);
708CREATE POLICY p2 ON document FOR INSERT WITH CHECK (dauthor = current_user);
709CREATE POLICY p3 ON document FOR UPDATE
710  USING (cid = (SELECT cid from category WHERE cname = 'novel'))
711  WITH CHECK (dauthor = current_user);
712
713SET SESSION AUTHORIZATION regress_rls_bob;
714
715-- Exists...
716SELECT * FROM document WHERE did = 2;
717
718-- ...so violates actual WITH CHECK OPTION within UPDATE (not INSERT, since
719-- alternative UPDATE path happens to be taken):
720INSERT INTO document VALUES (2, (SELECT cid from category WHERE cname = 'novel'), 1, 'regress_rls_carol', 'my first novel')
721    ON CONFLICT (did) DO UPDATE SET dtitle = EXCLUDED.dtitle, dauthor = EXCLUDED.dauthor;
722
723-- Violates USING qual for UPDATE policy p3.
724--
725-- UPDATE path is taken, but UPDATE fails purely because *existing* row to be
726-- updated is not a "novel"/cid 11 (row is not leaked, even though we have
727-- SELECT privileges sufficient to see the row in this instance):
728INSERT INTO document VALUES (33, 22, 1, 'regress_rls_bob', 'okay science fiction'); -- preparation for next statement
729INSERT INTO document VALUES (33, (SELECT cid from category WHERE cname = 'novel'), 1, 'regress_rls_bob', 'Some novel, replaces sci-fi') -- takes UPDATE path
730    ON CONFLICT (did) DO UPDATE SET dtitle = EXCLUDED.dtitle;
731-- Fine (we UPDATE, since INSERT WCOs and UPDATE security barrier quals + WCOs
732-- not violated):
733INSERT INTO document VALUES (2, (SELECT cid from category WHERE cname = 'novel'), 1, 'regress_rls_bob', 'my first novel')
734    ON CONFLICT (did) DO UPDATE SET dtitle = EXCLUDED.dtitle RETURNING *;
735-- Fine (we INSERT, so "cid = 33" ("technology") isn't evaluated):
736INSERT INTO document VALUES (78, (SELECT cid from category WHERE cname = 'novel'), 1, 'regress_rls_bob', 'some technology novel')
737    ON CONFLICT (did) DO UPDATE SET dtitle = EXCLUDED.dtitle, cid = 33 RETURNING *;
738-- Fine (same query, but we UPDATE, so "cid = 33", ("technology") is not the
739-- case in respect of *existing* tuple):
740INSERT INTO document VALUES (78, (SELECT cid from category WHERE cname = 'novel'), 1, 'regress_rls_bob', 'some technology novel')
741    ON CONFLICT (did) DO UPDATE SET dtitle = EXCLUDED.dtitle, cid = 33 RETURNING *;
742-- Same query a third time, but now fails due to existing tuple finally not
743-- passing quals:
744INSERT INTO document VALUES (78, (SELECT cid from category WHERE cname = 'novel'), 1, 'regress_rls_bob', 'some technology novel')
745    ON CONFLICT (did) DO UPDATE SET dtitle = EXCLUDED.dtitle, cid = 33 RETURNING *;
746-- Don't fail just because INSERT doesn't satisfy WITH CHECK option that
747-- originated as a barrier/USING() qual from the UPDATE.  Note that the UPDATE
748-- path *isn't* taken, and so UPDATE-related policy does not apply:
749INSERT INTO document VALUES (79, (SELECT cid from category WHERE cname = 'technology'), 1, 'regress_rls_bob', 'technology book, can only insert')
750    ON CONFLICT (did) DO UPDATE SET dtitle = EXCLUDED.dtitle RETURNING *;
751-- But this time, the same statement fails, because the UPDATE path is taken,
752-- and updating the row just inserted falls afoul of security barrier qual
753-- (enforced as WCO) -- what we might have updated target tuple to is
754-- irrelevant, in fact.
755INSERT INTO document VALUES (79, (SELECT cid from category WHERE cname = 'technology'), 1, 'regress_rls_bob', 'technology book, can only insert')
756    ON CONFLICT (did) DO UPDATE SET dtitle = EXCLUDED.dtitle RETURNING *;
757
758-- Test default USING qual enforced as WCO
759SET SESSION AUTHORIZATION regress_rls_alice;
760DROP POLICY p1 ON document;
761DROP POLICY p2 ON document;
762DROP POLICY p3 ON document;
763
764CREATE POLICY p3_with_default ON document FOR UPDATE
765  USING (cid = (SELECT cid from category WHERE cname = 'novel'));
766
767SET SESSION AUTHORIZATION regress_rls_bob;
768-- Just because WCO-style enforcement of USING quals occurs with
769-- existing/target tuple does not mean that the implementation can be allowed
770-- to fail to also enforce this qual against the final tuple appended to
771-- relation (since in the absence of an explicit WCO, this is also interpreted
772-- as an UPDATE/ALL WCO in general).
773--
774-- UPDATE path is taken here (fails due to existing tuple).  Note that this is
775-- not reported as a "USING expression", because it's an RLS UPDATE check that originated as
776-- a USING qual for the purposes of RLS in general, as opposed to an explicit
777-- USING qual that is ordinarily a security barrier.  We leave it up to the
778-- UPDATE to make this fail:
779INSERT INTO document VALUES (79, (SELECT cid from category WHERE cname = 'technology'), 1, 'regress_rls_bob', 'technology book, can only insert')
780    ON CONFLICT (did) DO UPDATE SET dtitle = EXCLUDED.dtitle RETURNING *;
781
782-- UPDATE path is taken here.  Existing tuple passes, since its cid
783-- corresponds to "novel", but default USING qual is enforced against
784-- post-UPDATE tuple too (as always when updating with a policy that lacks an
785-- explicit WCO), and so this fails:
786INSERT INTO document VALUES (2, (SELECT cid from category WHERE cname = 'technology'), 1, 'regress_rls_bob', 'my first novel')
787    ON CONFLICT (did) DO UPDATE SET cid = EXCLUDED.cid, dtitle = EXCLUDED.dtitle RETURNING *;
788
789SET SESSION AUTHORIZATION regress_rls_alice;
790DROP POLICY p3_with_default ON document;
791
792--
793-- Test ALL policies with ON CONFLICT DO UPDATE (much the same as existing UPDATE
794-- tests)
795--
796CREATE POLICY p3_with_all ON document FOR ALL
797  USING (cid = (SELECT cid from category WHERE cname = 'novel'))
798  WITH CHECK (dauthor = current_user);
799
800SET SESSION AUTHORIZATION regress_rls_bob;
801
802-- Fails, since ALL WCO is enforced in insert path:
803INSERT INTO document VALUES (80, (SELECT cid from category WHERE cname = 'novel'), 1, 'regress_rls_carol', 'my first novel')
804    ON CONFLICT (did) DO UPDATE SET dtitle = EXCLUDED.dtitle, cid = 33;
805-- Fails, since ALL policy USING qual is enforced (existing, target tuple is in
806-- violation, since it has the "manga" cid):
807INSERT INTO document VALUES (4, (SELECT cid from category WHERE cname = 'novel'), 1, 'regress_rls_bob', 'my first novel')
808    ON CONFLICT (did) DO UPDATE SET dtitle = EXCLUDED.dtitle;
809-- Fails, since ALL WCO are enforced:
810INSERT INTO document VALUES (1, (SELECT cid from category WHERE cname = 'novel'), 1, 'regress_rls_bob', 'my first novel')
811    ON CONFLICT (did) DO UPDATE SET dauthor = 'regress_rls_carol';
812
813--
814-- ROLE/GROUP
815--
816SET SESSION AUTHORIZATION regress_rls_alice;
817CREATE TABLE z1 (a int, b text);
818CREATE TABLE z2 (a int, b text);
819
820GRANT SELECT ON z1,z2 TO regress_rls_group1, regress_rls_group2,
821    regress_rls_bob, regress_rls_carol;
822
823INSERT INTO z1 VALUES
824    (1, 'aba'),
825    (2, 'bbb'),
826    (3, 'ccc'),
827    (4, 'dad');
828
829CREATE POLICY p1 ON z1 TO regress_rls_group1 USING (a % 2 = 0);
830CREATE POLICY p2 ON z1 TO regress_rls_group2 USING (a % 2 = 1);
831
832ALTER TABLE z1 ENABLE ROW LEVEL SECURITY;
833
834SET SESSION AUTHORIZATION regress_rls_bob;
835SELECT * FROM z1 WHERE f_leak(b);
836EXPLAIN (COSTS OFF) SELECT * FROM z1 WHERE f_leak(b);
837
838PREPARE plancache_test AS SELECT * FROM z1 WHERE f_leak(b);
839EXPLAIN (COSTS OFF) EXECUTE plancache_test;
840
841PREPARE plancache_test2 AS WITH q AS MATERIALIZED (SELECT * FROM z1 WHERE f_leak(b)) SELECT * FROM q,z2;
842EXPLAIN (COSTS OFF) EXECUTE plancache_test2;
843
844PREPARE plancache_test3 AS WITH q AS MATERIALIZED (SELECT * FROM z2) SELECT * FROM q,z1 WHERE f_leak(z1.b);
845EXPLAIN (COSTS OFF) EXECUTE plancache_test3;
846
847SET ROLE regress_rls_group1;
848SELECT * FROM z1 WHERE f_leak(b);
849EXPLAIN (COSTS OFF) SELECT * FROM z1 WHERE f_leak(b);
850
851EXPLAIN (COSTS OFF) EXECUTE plancache_test;
852EXPLAIN (COSTS OFF) EXECUTE plancache_test2;
853EXPLAIN (COSTS OFF) EXECUTE plancache_test3;
854
855SET SESSION AUTHORIZATION regress_rls_carol;
856SELECT * FROM z1 WHERE f_leak(b);
857EXPLAIN (COSTS OFF) SELECT * FROM z1 WHERE f_leak(b);
858
859EXPLAIN (COSTS OFF) EXECUTE plancache_test;
860EXPLAIN (COSTS OFF) EXECUTE plancache_test2;
861EXPLAIN (COSTS OFF) EXECUTE plancache_test3;
862
863SET ROLE regress_rls_group2;
864SELECT * FROM z1 WHERE f_leak(b);
865EXPLAIN (COSTS OFF) SELECT * FROM z1 WHERE f_leak(b);
866
867EXPLAIN (COSTS OFF) EXECUTE plancache_test;
868EXPLAIN (COSTS OFF) EXECUTE plancache_test2;
869EXPLAIN (COSTS OFF) EXECUTE plancache_test3;
870
871--
872-- Views should follow policy for view owner.
873--
874-- View and Table owner are the same.
875SET SESSION AUTHORIZATION regress_rls_alice;
876CREATE VIEW rls_view AS SELECT * FROM z1 WHERE f_leak(b);
877GRANT SELECT ON rls_view TO regress_rls_bob;
878
879-- Query as role that is not owner of view or table.  Should return all records.
880SET SESSION AUTHORIZATION regress_rls_bob;
881SELECT * FROM rls_view;
882EXPLAIN (COSTS OFF) SELECT * FROM rls_view;
883
884-- Query as view/table owner.  Should return all records.
885SET SESSION AUTHORIZATION regress_rls_alice;
886SELECT * FROM rls_view;
887EXPLAIN (COSTS OFF) SELECT * FROM rls_view;
888DROP VIEW rls_view;
889
890-- View and Table owners are different.
891SET SESSION AUTHORIZATION regress_rls_bob;
892CREATE VIEW rls_view AS SELECT * FROM z1 WHERE f_leak(b);
893GRANT SELECT ON rls_view TO regress_rls_alice;
894
895-- Query as role that is not owner of view but is owner of table.
896-- Should return records based on view owner policies.
897SET SESSION AUTHORIZATION regress_rls_alice;
898SELECT * FROM rls_view;
899EXPLAIN (COSTS OFF) SELECT * FROM rls_view;
900
901-- Query as role that is not owner of table but is owner of view.
902-- Should return records based on view owner policies.
903SET SESSION AUTHORIZATION regress_rls_bob;
904SELECT * FROM rls_view;
905EXPLAIN (COSTS OFF) SELECT * FROM rls_view;
906
907-- Query as role that is not the owner of the table or view without permissions.
908SET SESSION AUTHORIZATION regress_rls_carol;
909SELECT * FROM rls_view; --fail - permission denied.
910EXPLAIN (COSTS OFF) SELECT * FROM rls_view; --fail - permission denied.
911
912-- Query as role that is not the owner of the table or view with permissions.
913SET SESSION AUTHORIZATION regress_rls_bob;
914GRANT SELECT ON rls_view TO regress_rls_carol;
915SELECT * FROM rls_view;
916EXPLAIN (COSTS OFF) SELECT * FROM rls_view;
917
918SET SESSION AUTHORIZATION regress_rls_bob;
919DROP VIEW rls_view;
920
921--
922-- Command specific
923--
924SET SESSION AUTHORIZATION regress_rls_alice;
925
926CREATE TABLE x1 (a int, b text, c text);
927GRANT ALL ON x1 TO PUBLIC;
928
929INSERT INTO x1 VALUES
930    (1, 'abc', 'regress_rls_bob'),
931    (2, 'bcd', 'regress_rls_bob'),
932    (3, 'cde', 'regress_rls_carol'),
933    (4, 'def', 'regress_rls_carol'),
934    (5, 'efg', 'regress_rls_bob'),
935    (6, 'fgh', 'regress_rls_bob'),
936    (7, 'fgh', 'regress_rls_carol'),
937    (8, 'fgh', 'regress_rls_carol');
938
939CREATE POLICY p0 ON x1 FOR ALL USING (c = current_user);
940CREATE POLICY p1 ON x1 FOR SELECT USING (a % 2 = 0);
941CREATE POLICY p2 ON x1 FOR INSERT WITH CHECK (a % 2 = 1);
942CREATE POLICY p3 ON x1 FOR UPDATE USING (a % 2 = 0);
943CREATE POLICY p4 ON x1 FOR DELETE USING (a < 8);
944
945ALTER TABLE x1 ENABLE ROW LEVEL SECURITY;
946
947SET SESSION AUTHORIZATION regress_rls_bob;
948SELECT * FROM x1 WHERE f_leak(b) ORDER BY a ASC;
949UPDATE x1 SET b = b || '_updt' WHERE f_leak(b) RETURNING *;
950
951SET SESSION AUTHORIZATION regress_rls_carol;
952SELECT * FROM x1 WHERE f_leak(b) ORDER BY a ASC;
953UPDATE x1 SET b = b || '_updt' WHERE f_leak(b) RETURNING *;
954DELETE FROM x1 WHERE f_leak(b) RETURNING *;
955
956--
957-- Duplicate Policy Names
958--
959SET SESSION AUTHORIZATION regress_rls_alice;
960CREATE TABLE y1 (a int, b text);
961CREATE TABLE y2 (a int, b text);
962
963GRANT ALL ON y1, y2 TO regress_rls_bob;
964
965CREATE POLICY p1 ON y1 FOR ALL USING (a % 2 = 0);
966CREATE POLICY p2 ON y1 FOR SELECT USING (a > 2);
967CREATE POLICY p1 ON y1 FOR SELECT USING (a % 2 = 1);  --fail
968CREATE POLICY p1 ON y2 FOR ALL USING (a % 2 = 0);  --OK
969
970ALTER TABLE y1 ENABLE ROW LEVEL SECURITY;
971ALTER TABLE y2 ENABLE ROW LEVEL SECURITY;
972
973--
974-- Expression structure with SBV
975--
976-- Create view as table owner.  RLS should NOT be applied.
977SET SESSION AUTHORIZATION regress_rls_alice;
978CREATE VIEW rls_sbv WITH (security_barrier) AS
979    SELECT * FROM y1 WHERE f_leak(b);
980EXPLAIN (COSTS OFF) SELECT * FROM rls_sbv WHERE (a = 1);
981DROP VIEW rls_sbv;
982
983-- Create view as role that does not own table.  RLS should be applied.
984SET SESSION AUTHORIZATION regress_rls_bob;
985CREATE VIEW rls_sbv WITH (security_barrier) AS
986    SELECT * FROM y1 WHERE f_leak(b);
987EXPLAIN (COSTS OFF) SELECT * FROM rls_sbv WHERE (a = 1);
988DROP VIEW rls_sbv;
989
990--
991-- Expression structure
992--
993SET SESSION AUTHORIZATION regress_rls_alice;
994INSERT INTO y2 (SELECT x, md5(x::text) FROM generate_series(0,20) x);
995CREATE POLICY p2 ON y2 USING (a % 3 = 0);
996CREATE POLICY p3 ON y2 USING (a % 4 = 0);
997
998SET SESSION AUTHORIZATION regress_rls_bob;
999SELECT * FROM y2 WHERE f_leak(b);
1000EXPLAIN (COSTS OFF) SELECT * FROM y2 WHERE f_leak(b);
1001
1002--
1003-- Qual push-down of leaky functions, when not referring to table
1004--
1005SELECT * FROM y2 WHERE f_leak('abc');
1006EXPLAIN (COSTS OFF) SELECT * FROM y2 WHERE f_leak('abc');
1007
1008CREATE TABLE test_qual_pushdown (
1009    abc text
1010);
1011
1012INSERT INTO test_qual_pushdown VALUES ('abc'),('def');
1013
1014SELECT * FROM y2 JOIN test_qual_pushdown ON (b = abc) WHERE f_leak(abc);
1015EXPLAIN (COSTS OFF) SELECT * FROM y2 JOIN test_qual_pushdown ON (b = abc) WHERE f_leak(abc);
1016
1017SELECT * FROM y2 JOIN test_qual_pushdown ON (b = abc) WHERE f_leak(b);
1018EXPLAIN (COSTS OFF) SELECT * FROM y2 JOIN test_qual_pushdown ON (b = abc) WHERE f_leak(b);
1019
1020DROP TABLE test_qual_pushdown;
1021
1022--
1023-- Plancache invalidate on user change.
1024--
1025RESET SESSION AUTHORIZATION;
1026
1027DROP TABLE t1 CASCADE;
1028
1029CREATE TABLE t1 (a integer);
1030
1031GRANT SELECT ON t1 TO regress_rls_bob, regress_rls_carol;
1032
1033CREATE POLICY p1 ON t1 TO regress_rls_bob USING ((a % 2) = 0);
1034CREATE POLICY p2 ON t1 TO regress_rls_carol USING ((a % 4) = 0);
1035
1036ALTER TABLE t1 ENABLE ROW LEVEL SECURITY;
1037
1038-- Prepare as regress_rls_bob
1039SET ROLE regress_rls_bob;
1040PREPARE role_inval AS SELECT * FROM t1;
1041-- Check plan
1042EXPLAIN (COSTS OFF) EXECUTE role_inval;
1043
1044-- Change to regress_rls_carol
1045SET ROLE regress_rls_carol;
1046-- Check plan- should be different
1047EXPLAIN (COSTS OFF) EXECUTE role_inval;
1048
1049-- Change back to regress_rls_bob
1050SET ROLE regress_rls_bob;
1051-- Check plan- should be back to original
1052EXPLAIN (COSTS OFF) EXECUTE role_inval;
1053
1054--
1055-- CTE and RLS
1056--
1057RESET SESSION AUTHORIZATION;
1058DROP TABLE t1 CASCADE;
1059CREATE TABLE t1 (a integer, b text);
1060CREATE POLICY p1 ON t1 USING (a % 2 = 0);
1061
1062ALTER TABLE t1 ENABLE ROW LEVEL SECURITY;
1063
1064GRANT ALL ON t1 TO regress_rls_bob;
1065
1066INSERT INTO t1 (SELECT x, md5(x::text) FROM generate_series(0,20) x);
1067
1068SET SESSION AUTHORIZATION regress_rls_bob;
1069
1070WITH cte1 AS MATERIALIZED (SELECT * FROM t1 WHERE f_leak(b)) SELECT * FROM cte1;
1071EXPLAIN (COSTS OFF)
1072WITH cte1 AS MATERIALIZED (SELECT * FROM t1 WHERE f_leak(b)) SELECT * FROM cte1;
1073
1074WITH cte1 AS (UPDATE t1 SET a = a + 1 RETURNING *) SELECT * FROM cte1; --fail
1075WITH cte1 AS (UPDATE t1 SET a = a RETURNING *) SELECT * FROM cte1; --ok
1076
1077WITH cte1 AS (INSERT INTO t1 VALUES (21, 'Fail') RETURNING *) SELECT * FROM cte1; --fail
1078WITH cte1 AS (INSERT INTO t1 VALUES (20, 'Success') RETURNING *) SELECT * FROM cte1; --ok
1079
1080--
1081-- Rename Policy
1082--
1083RESET SESSION AUTHORIZATION;
1084ALTER POLICY p1 ON t1 RENAME TO p1; --fail
1085
1086SELECT polname, relname
1087    FROM pg_policy pol
1088    JOIN pg_class pc ON (pc.oid = pol.polrelid)
1089    WHERE relname = 't1';
1090
1091ALTER POLICY p1 ON t1 RENAME TO p2; --ok
1092
1093SELECT polname, relname
1094    FROM pg_policy pol
1095    JOIN pg_class pc ON (pc.oid = pol.polrelid)
1096    WHERE relname = 't1';
1097
1098--
1099-- Check INSERT SELECT
1100--
1101SET SESSION AUTHORIZATION regress_rls_bob;
1102CREATE TABLE t2 (a integer, b text);
1103INSERT INTO t2 (SELECT * FROM t1);
1104EXPLAIN (COSTS OFF) INSERT INTO t2 (SELECT * FROM t1);
1105SELECT * FROM t2;
1106EXPLAIN (COSTS OFF) SELECT * FROM t2;
1107CREATE TABLE t3 AS SELECT * FROM t1;
1108SELECT * FROM t3;
1109SELECT * INTO t4 FROM t1;
1110SELECT * FROM t4;
1111
1112--
1113-- RLS with JOIN
1114--
1115SET SESSION AUTHORIZATION regress_rls_alice;
1116CREATE TABLE blog (id integer, author text, post text);
1117CREATE TABLE comment (blog_id integer, message text);
1118
1119GRANT ALL ON blog, comment TO regress_rls_bob;
1120
1121CREATE POLICY blog_1 ON blog USING (id % 2 = 0);
1122
1123ALTER TABLE blog ENABLE ROW LEVEL SECURITY;
1124
1125INSERT INTO blog VALUES
1126    (1, 'alice', 'blog #1'),
1127    (2, 'bob', 'blog #1'),
1128    (3, 'alice', 'blog #2'),
1129    (4, 'alice', 'blog #3'),
1130    (5, 'john', 'blog #1');
1131
1132INSERT INTO comment VALUES
1133    (1, 'cool blog'),
1134    (1, 'fun blog'),
1135    (3, 'crazy blog'),
1136    (5, 'what?'),
1137    (4, 'insane!'),
1138    (2, 'who did it?');
1139
1140SET SESSION AUTHORIZATION regress_rls_bob;
1141-- Check RLS JOIN with Non-RLS.
1142SELECT id, author, message FROM blog JOIN comment ON id = blog_id;
1143-- Check Non-RLS JOIN with RLS.
1144SELECT id, author, message FROM comment JOIN blog ON id = blog_id;
1145
1146SET SESSION AUTHORIZATION regress_rls_alice;
1147CREATE POLICY comment_1 ON comment USING (blog_id < 4);
1148
1149ALTER TABLE comment ENABLE ROW LEVEL SECURITY;
1150
1151SET SESSION AUTHORIZATION regress_rls_bob;
1152-- Check RLS JOIN RLS
1153SELECT id, author, message FROM blog JOIN comment ON id = blog_id;
1154SELECT id, author, message FROM comment JOIN blog ON id = blog_id;
1155
1156SET SESSION AUTHORIZATION regress_rls_alice;
1157DROP TABLE blog, comment;
1158
1159--
1160-- Default Deny Policy
1161--
1162RESET SESSION AUTHORIZATION;
1163DROP POLICY p2 ON t1;
1164ALTER TABLE t1 OWNER TO regress_rls_alice;
1165
1166-- Check that default deny does not apply to superuser.
1167RESET SESSION AUTHORIZATION;
1168SELECT * FROM t1;
1169EXPLAIN (COSTS OFF) SELECT * FROM t1;
1170
1171-- Check that default deny does not apply to table owner.
1172SET SESSION AUTHORIZATION regress_rls_alice;
1173SELECT * FROM t1;
1174EXPLAIN (COSTS OFF) SELECT * FROM t1;
1175
1176-- Check that default deny applies to non-owner/non-superuser when RLS on.
1177SET SESSION AUTHORIZATION regress_rls_bob;
1178SET row_security TO ON;
1179SELECT * FROM t1;
1180EXPLAIN (COSTS OFF) SELECT * FROM t1;
1181SET SESSION AUTHORIZATION regress_rls_bob;
1182SELECT * FROM t1;
1183EXPLAIN (COSTS OFF) SELECT * FROM t1;
1184
1185--
1186-- COPY TO/FROM
1187--
1188
1189RESET SESSION AUTHORIZATION;
1190DROP TABLE copy_t CASCADE;
1191CREATE TABLE copy_t (a integer, b text);
1192CREATE POLICY p1 ON copy_t USING (a % 2 = 0);
1193
1194ALTER TABLE copy_t ENABLE ROW LEVEL SECURITY;
1195
1196GRANT ALL ON copy_t TO regress_rls_bob, regress_rls_exempt_user;
1197
1198INSERT INTO copy_t (SELECT x, md5(x::text) FROM generate_series(0,10) x);
1199
1200-- Check COPY TO as Superuser/owner.
1201RESET SESSION AUTHORIZATION;
1202SET row_security TO OFF;
1203COPY (SELECT * FROM copy_t ORDER BY a ASC) TO STDOUT WITH DELIMITER ',';
1204SET row_security TO ON;
1205COPY (SELECT * FROM copy_t ORDER BY a ASC) TO STDOUT WITH DELIMITER ',';
1206
1207-- Check COPY TO as user with permissions.
1208SET SESSION AUTHORIZATION regress_rls_bob;
1209SET row_security TO OFF;
1210COPY (SELECT * FROM copy_t ORDER BY a ASC) TO STDOUT WITH DELIMITER ','; --fail - would be affected by RLS
1211SET row_security TO ON;
1212COPY (SELECT * FROM copy_t ORDER BY a ASC) TO STDOUT WITH DELIMITER ','; --ok
1213
1214-- Check COPY TO as user with permissions and BYPASSRLS
1215SET SESSION AUTHORIZATION regress_rls_exempt_user;
1216SET row_security TO OFF;
1217COPY (SELECT * FROM copy_t ORDER BY a ASC) TO STDOUT WITH DELIMITER ','; --ok
1218SET row_security TO ON;
1219COPY (SELECT * FROM copy_t ORDER BY a ASC) TO STDOUT WITH DELIMITER ','; --ok
1220
1221-- Check COPY TO as user without permissions. SET row_security TO OFF;
1222SET SESSION AUTHORIZATION regress_rls_carol;
1223SET row_security TO OFF;
1224COPY (SELECT * FROM copy_t ORDER BY a ASC) TO STDOUT WITH DELIMITER ','; --fail - would be affected by RLS
1225SET row_security TO ON;
1226COPY (SELECT * FROM copy_t ORDER BY a ASC) TO STDOUT WITH DELIMITER ','; --fail - permission denied
1227
1228-- Check COPY relation TO; keep it just one row to avoid reordering issues
1229RESET SESSION AUTHORIZATION;
1230SET row_security TO ON;
1231CREATE TABLE copy_rel_to (a integer, b text);
1232CREATE POLICY p1 ON copy_rel_to USING (a % 2 = 0);
1233
1234ALTER TABLE copy_rel_to ENABLE ROW LEVEL SECURITY;
1235
1236GRANT ALL ON copy_rel_to TO regress_rls_bob, regress_rls_exempt_user;
1237
1238INSERT INTO copy_rel_to VALUES (1, md5('1'));
1239
1240-- Check COPY TO as Superuser/owner.
1241RESET SESSION AUTHORIZATION;
1242SET row_security TO OFF;
1243COPY copy_rel_to TO STDOUT WITH DELIMITER ',';
1244SET row_security TO ON;
1245COPY copy_rel_to TO STDOUT WITH DELIMITER ',';
1246
1247-- Check COPY TO as user with permissions.
1248SET SESSION AUTHORIZATION regress_rls_bob;
1249SET row_security TO OFF;
1250COPY copy_rel_to TO STDOUT WITH DELIMITER ','; --fail - would be affected by RLS
1251SET row_security TO ON;
1252COPY copy_rel_to TO STDOUT WITH DELIMITER ','; --ok
1253
1254-- Check COPY TO as user with permissions and BYPASSRLS
1255SET SESSION AUTHORIZATION regress_rls_exempt_user;
1256SET row_security TO OFF;
1257COPY copy_rel_to TO STDOUT WITH DELIMITER ','; --ok
1258SET row_security TO ON;
1259COPY copy_rel_to TO STDOUT WITH DELIMITER ','; --ok
1260
1261-- Check COPY TO as user without permissions. SET row_security TO OFF;
1262SET SESSION AUTHORIZATION regress_rls_carol;
1263SET row_security TO OFF;
1264COPY copy_rel_to TO STDOUT WITH DELIMITER ','; --fail - permission denied
1265SET row_security TO ON;
1266COPY copy_rel_to TO STDOUT WITH DELIMITER ','; --fail - permission denied
1267
1268-- Check COPY FROM as Superuser/owner.
1269RESET SESSION AUTHORIZATION;
1270SET row_security TO OFF;
1271COPY copy_t FROM STDIN; --ok
12721	abc
12732	bcd
12743	cde
12754	def
1276\.
1277SET row_security TO ON;
1278COPY copy_t FROM STDIN; --ok
12791	abc
12802	bcd
12813	cde
12824	def
1283\.
1284
1285-- Check COPY FROM as user with permissions.
1286SET SESSION AUTHORIZATION regress_rls_bob;
1287SET row_security TO OFF;
1288COPY copy_t FROM STDIN; --fail - would be affected by RLS.
1289SET row_security TO ON;
1290COPY copy_t FROM STDIN; --fail - COPY FROM not supported by RLS.
1291
1292-- Check COPY FROM as user with permissions and BYPASSRLS
1293SET SESSION AUTHORIZATION regress_rls_exempt_user;
1294SET row_security TO ON;
1295COPY copy_t FROM STDIN; --ok
12961	abc
12972	bcd
12983	cde
12994	def
1300\.
1301
1302-- Check COPY FROM as user without permissions.
1303SET SESSION AUTHORIZATION regress_rls_carol;
1304SET row_security TO OFF;
1305COPY copy_t FROM STDIN; --fail - permission denied.
1306SET row_security TO ON;
1307COPY copy_t FROM STDIN; --fail - permission denied.
1308
1309RESET SESSION AUTHORIZATION;
1310DROP TABLE copy_t;
1311DROP TABLE copy_rel_to CASCADE;
1312
1313-- Check WHERE CURRENT OF
1314SET SESSION AUTHORIZATION regress_rls_alice;
1315
1316CREATE TABLE current_check (currentid int, payload text, rlsuser text);
1317GRANT ALL ON current_check TO PUBLIC;
1318
1319INSERT INTO current_check VALUES
1320    (1, 'abc', 'regress_rls_bob'),
1321    (2, 'bcd', 'regress_rls_bob'),
1322    (3, 'cde', 'regress_rls_bob'),
1323    (4, 'def', 'regress_rls_bob');
1324
1325CREATE POLICY p1 ON current_check FOR SELECT USING (currentid % 2 = 0);
1326CREATE POLICY p2 ON current_check FOR DELETE USING (currentid = 4 AND rlsuser = current_user);
1327CREATE POLICY p3 ON current_check FOR UPDATE USING (currentid = 4) WITH CHECK (rlsuser = current_user);
1328
1329ALTER TABLE current_check ENABLE ROW LEVEL SECURITY;
1330
1331SET SESSION AUTHORIZATION regress_rls_bob;
1332
1333-- Can SELECT even rows
1334SELECT * FROM current_check;
1335
1336-- Cannot UPDATE row 2
1337UPDATE current_check SET payload = payload || '_new' WHERE currentid = 2 RETURNING *;
1338
1339BEGIN;
1340
1341DECLARE current_check_cursor SCROLL CURSOR FOR SELECT * FROM current_check;
1342-- Returns rows that can be seen according to SELECT policy, like plain SELECT
1343-- above (even rows)
1344FETCH ABSOLUTE 1 FROM current_check_cursor;
1345-- Still cannot UPDATE row 2 through cursor
1346UPDATE current_check SET payload = payload || '_new' WHERE CURRENT OF current_check_cursor RETURNING *;
1347-- Can update row 4 through cursor, which is the next visible row
1348FETCH RELATIVE 1 FROM current_check_cursor;
1349UPDATE current_check SET payload = payload || '_new' WHERE CURRENT OF current_check_cursor RETURNING *;
1350SELECT * FROM current_check;
1351-- Plan should be a subquery TID scan
1352EXPLAIN (COSTS OFF) UPDATE current_check SET payload = payload WHERE CURRENT OF current_check_cursor;
1353-- Similarly can only delete row 4
1354FETCH ABSOLUTE 1 FROM current_check_cursor;
1355DELETE FROM current_check WHERE CURRENT OF current_check_cursor RETURNING *;
1356FETCH RELATIVE 1 FROM current_check_cursor;
1357DELETE FROM current_check WHERE CURRENT OF current_check_cursor RETURNING *;
1358SELECT * FROM current_check;
1359
1360COMMIT;
1361
1362--
1363-- check pg_stats view filtering
1364--
1365SET row_security TO ON;
1366SET SESSION AUTHORIZATION regress_rls_alice;
1367ANALYZE current_check;
1368-- Stats visible
1369SELECT row_security_active('current_check');
1370SELECT attname, most_common_vals FROM pg_stats
1371  WHERE tablename = 'current_check'
1372  ORDER BY 1;
1373
1374SET SESSION AUTHORIZATION regress_rls_bob;
1375-- Stats not visible
1376SELECT row_security_active('current_check');
1377SELECT attname, most_common_vals FROM pg_stats
1378  WHERE tablename = 'current_check'
1379  ORDER BY 1;
1380
1381--
1382-- Collation support
1383--
1384BEGIN;
1385CREATE TABLE coll_t (c) AS VALUES ('bar'::text);
1386CREATE POLICY coll_p ON coll_t USING (c < ('foo'::text COLLATE "C"));
1387ALTER TABLE coll_t ENABLE ROW LEVEL SECURITY;
1388GRANT SELECT ON coll_t TO regress_rls_alice;
1389SELECT (string_to_array(polqual, ':'))[7] AS inputcollid FROM pg_policy WHERE polrelid = 'coll_t'::regclass;
1390SET SESSION AUTHORIZATION regress_rls_alice;
1391SELECT * FROM coll_t;
1392ROLLBACK;
1393
1394--
1395-- Shared Object Dependencies
1396--
1397RESET SESSION AUTHORIZATION;
1398BEGIN;
1399CREATE ROLE regress_rls_eve;
1400CREATE ROLE regress_rls_frank;
1401CREATE TABLE tbl1 (c) AS VALUES ('bar'::text);
1402GRANT SELECT ON TABLE tbl1 TO regress_rls_eve;
1403CREATE POLICY P ON tbl1 TO regress_rls_eve, regress_rls_frank USING (true);
1404SELECT refclassid::regclass, deptype
1405  FROM pg_depend
1406  WHERE classid = 'pg_policy'::regclass
1407  AND refobjid = 'tbl1'::regclass;
1408SELECT refclassid::regclass, deptype
1409  FROM pg_shdepend
1410  WHERE classid = 'pg_policy'::regclass
1411  AND refobjid IN ('regress_rls_eve'::regrole, 'regress_rls_frank'::regrole);
1412
1413SAVEPOINT q;
1414DROP ROLE regress_rls_eve; --fails due to dependency on POLICY p
1415ROLLBACK TO q;
1416
1417ALTER POLICY p ON tbl1 TO regress_rls_frank USING (true);
1418SAVEPOINT q;
1419DROP ROLE regress_rls_eve; --fails due to dependency on GRANT SELECT
1420ROLLBACK TO q;
1421
1422REVOKE ALL ON TABLE tbl1 FROM regress_rls_eve;
1423SAVEPOINT q;
1424DROP ROLE regress_rls_eve; --succeeds
1425ROLLBACK TO q;
1426
1427SAVEPOINT q;
1428DROP ROLE regress_rls_frank; --fails due to dependency on POLICY p
1429ROLLBACK TO q;
1430
1431DROP POLICY p ON tbl1;
1432SAVEPOINT q;
1433DROP ROLE regress_rls_frank; -- succeeds
1434ROLLBACK TO q;
1435
1436ROLLBACK; -- cleanup
1437
1438--
1439-- Converting table to view
1440--
1441BEGIN;
1442CREATE TABLE t (c int);
1443CREATE POLICY p ON t USING (c % 2 = 1);
1444ALTER TABLE t ENABLE ROW LEVEL SECURITY;
1445
1446SAVEPOINT q;
1447CREATE RULE "_RETURN" AS ON SELECT TO t DO INSTEAD
1448  SELECT * FROM generate_series(1,5) t0(c); -- fails due to row-level security enabled
1449ROLLBACK TO q;
1450
1451ALTER TABLE t DISABLE ROW LEVEL SECURITY;
1452SAVEPOINT q;
1453CREATE RULE "_RETURN" AS ON SELECT TO t DO INSTEAD
1454  SELECT * FROM generate_series(1,5) t0(c); -- fails due to policy p on t
1455ROLLBACK TO q;
1456
1457DROP POLICY p ON t;
1458CREATE RULE "_RETURN" AS ON SELECT TO t DO INSTEAD
1459  SELECT * FROM generate_series(1,5) t0(c); -- succeeds
1460ROLLBACK;
1461
1462--
1463-- Policy expression handling
1464--
1465BEGIN;
1466CREATE TABLE t (c) AS VALUES ('bar'::text);
1467CREATE POLICY p ON t USING (max(c)); -- fails: aggregate functions are not allowed in policy expressions
1468ROLLBACK;
1469
1470--
1471-- Non-target relations are only subject to SELECT policies
1472--
1473SET SESSION AUTHORIZATION regress_rls_alice;
1474CREATE TABLE r1 (a int);
1475CREATE TABLE r2 (a int);
1476INSERT INTO r1 VALUES (10), (20);
1477INSERT INTO r2 VALUES (10), (20);
1478
1479GRANT ALL ON r1, r2 TO regress_rls_bob;
1480
1481CREATE POLICY p1 ON r1 USING (true);
1482ALTER TABLE r1 ENABLE ROW LEVEL SECURITY;
1483
1484CREATE POLICY p1 ON r2 FOR SELECT USING (true);
1485CREATE POLICY p2 ON r2 FOR INSERT WITH CHECK (false);
1486CREATE POLICY p3 ON r2 FOR UPDATE USING (false);
1487CREATE POLICY p4 ON r2 FOR DELETE USING (false);
1488ALTER TABLE r2 ENABLE ROW LEVEL SECURITY;
1489
1490SET SESSION AUTHORIZATION regress_rls_bob;
1491SELECT * FROM r1;
1492SELECT * FROM r2;
1493
1494-- r2 is read-only
1495INSERT INTO r2 VALUES (2); -- Not allowed
1496UPDATE r2 SET a = 2 RETURNING *; -- Updates nothing
1497DELETE FROM r2 RETURNING *; -- Deletes nothing
1498
1499-- r2 can be used as a non-target relation in DML
1500INSERT INTO r1 SELECT a + 1 FROM r2 RETURNING *; -- OK
1501UPDATE r1 SET a = r2.a + 2 FROM r2 WHERE r1.a = r2.a RETURNING *; -- OK
1502DELETE FROM r1 USING r2 WHERE r1.a = r2.a + 2 RETURNING *; -- OK
1503SELECT * FROM r1;
1504SELECT * FROM r2;
1505
1506SET SESSION AUTHORIZATION regress_rls_alice;
1507DROP TABLE r1;
1508DROP TABLE r2;
1509
1510--
1511-- FORCE ROW LEVEL SECURITY applies RLS to owners too
1512--
1513SET SESSION AUTHORIZATION regress_rls_alice;
1514SET row_security = on;
1515CREATE TABLE r1 (a int);
1516INSERT INTO r1 VALUES (10), (20);
1517
1518CREATE POLICY p1 ON r1 USING (false);
1519ALTER TABLE r1 ENABLE ROW LEVEL SECURITY;
1520ALTER TABLE r1 FORCE ROW LEVEL SECURITY;
1521
1522-- No error, but no rows
1523TABLE r1;
1524
1525-- RLS error
1526INSERT INTO r1 VALUES (1);
1527
1528-- No error (unable to see any rows to update)
1529UPDATE r1 SET a = 1;
1530TABLE r1;
1531
1532-- No error (unable to see any rows to delete)
1533DELETE FROM r1;
1534TABLE r1;
1535
1536SET row_security = off;
1537-- these all fail, would be affected by RLS
1538TABLE r1;
1539UPDATE r1 SET a = 1;
1540DELETE FROM r1;
1541
1542DROP TABLE r1;
1543
1544--
1545-- FORCE ROW LEVEL SECURITY does not break RI
1546--
1547SET SESSION AUTHORIZATION regress_rls_alice;
1548SET row_security = on;
1549CREATE TABLE r1 (a int PRIMARY KEY);
1550CREATE TABLE r2 (a int REFERENCES r1);
1551INSERT INTO r1 VALUES (10), (20);
1552INSERT INTO r2 VALUES (10), (20);
1553
1554-- Create policies on r2 which prevent the
1555-- owner from seeing any rows, but RI should
1556-- still see them.
1557CREATE POLICY p1 ON r2 USING (false);
1558ALTER TABLE r2 ENABLE ROW LEVEL SECURITY;
1559ALTER TABLE r2 FORCE ROW LEVEL SECURITY;
1560
1561-- Errors due to rows in r2
1562DELETE FROM r1;
1563
1564-- Reset r2 to no-RLS
1565DROP POLICY p1 ON r2;
1566ALTER TABLE r2 NO FORCE ROW LEVEL SECURITY;
1567ALTER TABLE r2 DISABLE ROW LEVEL SECURITY;
1568
1569-- clean out r2 for INSERT test below
1570DELETE FROM r2;
1571
1572-- Change r1 to not allow rows to be seen
1573CREATE POLICY p1 ON r1 USING (false);
1574ALTER TABLE r1 ENABLE ROW LEVEL SECURITY;
1575ALTER TABLE r1 FORCE ROW LEVEL SECURITY;
1576
1577-- No rows seen
1578TABLE r1;
1579
1580-- No error, RI still sees that row exists in r1
1581INSERT INTO r2 VALUES (10);
1582
1583DROP TABLE r2;
1584DROP TABLE r1;
1585
1586-- Ensure cascaded DELETE works
1587CREATE TABLE r1 (a int PRIMARY KEY);
1588CREATE TABLE r2 (a int REFERENCES r1 ON DELETE CASCADE);
1589INSERT INTO r1 VALUES (10), (20);
1590INSERT INTO r2 VALUES (10), (20);
1591
1592-- Create policies on r2 which prevent the
1593-- owner from seeing any rows, but RI should
1594-- still see them.
1595CREATE POLICY p1 ON r2 USING (false);
1596ALTER TABLE r2 ENABLE ROW LEVEL SECURITY;
1597ALTER TABLE r2 FORCE ROW LEVEL SECURITY;
1598
1599-- Deletes all records from both
1600DELETE FROM r1;
1601
1602-- Remove FORCE from r2
1603ALTER TABLE r2 NO FORCE ROW LEVEL SECURITY;
1604
1605-- As owner, we now bypass RLS
1606-- verify no rows in r2 now
1607TABLE r2;
1608
1609DROP TABLE r2;
1610DROP TABLE r1;
1611
1612-- Ensure cascaded UPDATE works
1613CREATE TABLE r1 (a int PRIMARY KEY);
1614CREATE TABLE r2 (a int REFERENCES r1 ON UPDATE CASCADE);
1615INSERT INTO r1 VALUES (10), (20);
1616INSERT INTO r2 VALUES (10), (20);
1617
1618-- Create policies on r2 which prevent the
1619-- owner from seeing any rows, but RI should
1620-- still see them.
1621CREATE POLICY p1 ON r2 USING (false);
1622ALTER TABLE r2 ENABLE ROW LEVEL SECURITY;
1623ALTER TABLE r2 FORCE ROW LEVEL SECURITY;
1624
1625-- Updates records in both
1626UPDATE r1 SET a = a+5;
1627
1628-- Remove FORCE from r2
1629ALTER TABLE r2 NO FORCE ROW LEVEL SECURITY;
1630
1631-- As owner, we now bypass RLS
1632-- verify records in r2 updated
1633TABLE r2;
1634
1635DROP TABLE r2;
1636DROP TABLE r1;
1637
1638--
1639-- Test INSERT+RETURNING applies SELECT policies as
1640-- WithCheckOptions (meaning an error is thrown)
1641--
1642SET SESSION AUTHORIZATION regress_rls_alice;
1643SET row_security = on;
1644CREATE TABLE r1 (a int);
1645
1646CREATE POLICY p1 ON r1 FOR SELECT USING (false);
1647CREATE POLICY p2 ON r1 FOR INSERT WITH CHECK (true);
1648ALTER TABLE r1 ENABLE ROW LEVEL SECURITY;
1649ALTER TABLE r1 FORCE ROW LEVEL SECURITY;
1650
1651-- Works fine
1652INSERT INTO r1 VALUES (10), (20);
1653
1654-- No error, but no rows
1655TABLE r1;
1656
1657SET row_security = off;
1658-- fail, would be affected by RLS
1659TABLE r1;
1660
1661SET row_security = on;
1662
1663-- Error
1664INSERT INTO r1 VALUES (10), (20) RETURNING *;
1665
1666DROP TABLE r1;
1667
1668--
1669-- Test UPDATE+RETURNING applies SELECT policies as
1670-- WithCheckOptions (meaning an error is thrown)
1671--
1672SET SESSION AUTHORIZATION regress_rls_alice;
1673SET row_security = on;
1674CREATE TABLE r1 (a int PRIMARY KEY);
1675
1676CREATE POLICY p1 ON r1 FOR SELECT USING (a < 20);
1677CREATE POLICY p2 ON r1 FOR UPDATE USING (a < 20) WITH CHECK (true);
1678CREATE POLICY p3 ON r1 FOR INSERT WITH CHECK (true);
1679INSERT INTO r1 VALUES (10);
1680ALTER TABLE r1 ENABLE ROW LEVEL SECURITY;
1681ALTER TABLE r1 FORCE ROW LEVEL SECURITY;
1682
1683-- Works fine
1684UPDATE r1 SET a = 30;
1685
1686-- Show updated rows
1687ALTER TABLE r1 NO FORCE ROW LEVEL SECURITY;
1688TABLE r1;
1689-- reset value in r1 for test with RETURNING
1690UPDATE r1 SET a = 10;
1691
1692-- Verify row reset
1693TABLE r1;
1694
1695ALTER TABLE r1 FORCE ROW LEVEL SECURITY;
1696
1697-- Error
1698UPDATE r1 SET a = 30 RETURNING *;
1699
1700-- UPDATE path of INSERT ... ON CONFLICT DO UPDATE should also error out
1701INSERT INTO r1 VALUES (10)
1702    ON CONFLICT (a) DO UPDATE SET a = 30 RETURNING *;
1703
1704-- Should still error out without RETURNING (use of arbiter always requires
1705-- SELECT permissions)
1706INSERT INTO r1 VALUES (10)
1707    ON CONFLICT (a) DO UPDATE SET a = 30;
1708INSERT INTO r1 VALUES (10)
1709    ON CONFLICT ON CONSTRAINT r1_pkey DO UPDATE SET a = 30;
1710
1711DROP TABLE r1;
1712
1713-- Check dependency handling
1714RESET SESSION AUTHORIZATION;
1715CREATE TABLE dep1 (c1 int);
1716CREATE TABLE dep2 (c1 int);
1717
1718CREATE POLICY dep_p1 ON dep1 TO regress_rls_bob USING (c1 > (select max(dep2.c1) from dep2));
1719ALTER POLICY dep_p1 ON dep1 TO regress_rls_bob,regress_rls_carol;
1720
1721-- Should return one
1722SELECT count(*) = 1 FROM pg_depend
1723				   WHERE objid = (SELECT oid FROM pg_policy WHERE polname = 'dep_p1')
1724					 AND refobjid = (SELECT oid FROM pg_class WHERE relname = 'dep2');
1725
1726ALTER POLICY dep_p1 ON dep1 USING (true);
1727
1728-- Should return one
1729SELECT count(*) = 1 FROM pg_shdepend
1730				   WHERE objid = (SELECT oid FROM pg_policy WHERE polname = 'dep_p1')
1731					 AND refobjid = (SELECT oid FROM pg_authid WHERE rolname = 'regress_rls_bob');
1732
1733-- Should return one
1734SELECT count(*) = 1 FROM pg_shdepend
1735				   WHERE objid = (SELECT oid FROM pg_policy WHERE polname = 'dep_p1')
1736					 AND refobjid = (SELECT oid FROM pg_authid WHERE rolname = 'regress_rls_carol');
1737
1738-- Should return zero
1739SELECT count(*) = 0 FROM pg_depend
1740				   WHERE objid = (SELECT oid FROM pg_policy WHERE polname = 'dep_p1')
1741					 AND refobjid = (SELECT oid FROM pg_class WHERE relname = 'dep2');
1742
1743-- DROP OWNED BY testing
1744RESET SESSION AUTHORIZATION;
1745
1746CREATE ROLE regress_rls_dob_role1;
1747CREATE ROLE regress_rls_dob_role2;
1748
1749CREATE TABLE dob_t1 (c1 int);
1750CREATE TABLE dob_t2 (c1 int) PARTITION BY RANGE (c1);
1751
1752CREATE POLICY p1 ON dob_t1 TO regress_rls_dob_role1 USING (true);
1753DROP OWNED BY regress_rls_dob_role1;
1754DROP POLICY p1 ON dob_t1; -- should fail, already gone
1755
1756CREATE POLICY p1 ON dob_t1 TO regress_rls_dob_role1,regress_rls_dob_role2 USING (true);
1757DROP OWNED BY regress_rls_dob_role1;
1758DROP POLICY p1 ON dob_t1; -- should succeed
1759
1760-- same cases with duplicate polroles entries
1761CREATE POLICY p1 ON dob_t1 TO regress_rls_dob_role1,regress_rls_dob_role1 USING (true);
1762DROP OWNED BY regress_rls_dob_role1;
1763DROP POLICY p1 ON dob_t1; -- should fail, already gone
1764
1765CREATE POLICY p1 ON dob_t1 TO regress_rls_dob_role1,regress_rls_dob_role1,regress_rls_dob_role2 USING (true);
1766DROP OWNED BY regress_rls_dob_role1;
1767DROP POLICY p1 ON dob_t1; -- should succeed
1768
1769-- partitioned target
1770CREATE POLICY p1 ON dob_t2 TO regress_rls_dob_role1,regress_rls_dob_role2 USING (true);
1771DROP OWNED BY regress_rls_dob_role1;
1772DROP POLICY p1 ON dob_t2; -- should succeed
1773
1774DROP USER regress_rls_dob_role1;
1775DROP USER regress_rls_dob_role2;
1776
1777-- Bug #15708: view + table with RLS should check policies as view owner
1778CREATE TABLE ref_tbl (a int);
1779INSERT INTO ref_tbl VALUES (1);
1780
1781CREATE TABLE rls_tbl (a int);
1782INSERT INTO rls_tbl VALUES (10);
1783ALTER TABLE rls_tbl ENABLE ROW LEVEL SECURITY;
1784CREATE POLICY p1 ON rls_tbl USING (EXISTS (SELECT 1 FROM ref_tbl));
1785
1786GRANT SELECT ON ref_tbl TO regress_rls_bob;
1787GRANT SELECT ON rls_tbl TO regress_rls_bob;
1788
1789CREATE VIEW rls_view AS SELECT * FROM rls_tbl;
1790ALTER VIEW rls_view OWNER TO regress_rls_bob;
1791GRANT SELECT ON rls_view TO regress_rls_alice;
1792
1793SET SESSION AUTHORIZATION regress_rls_alice;
1794SELECT * FROM ref_tbl; -- Permission denied
1795SELECT * FROM rls_tbl; -- Permission denied
1796SELECT * FROM rls_view; -- OK
1797RESET SESSION AUTHORIZATION;
1798
1799DROP VIEW rls_view;
1800DROP TABLE rls_tbl;
1801DROP TABLE ref_tbl;
1802
1803-- Leaky operator test
1804CREATE TABLE rls_tbl (a int);
1805INSERT INTO rls_tbl SELECT x/10 FROM generate_series(1, 100) x;
1806ANALYZE rls_tbl;
1807
1808ALTER TABLE rls_tbl ENABLE ROW LEVEL SECURITY;
1809GRANT SELECT ON rls_tbl TO regress_rls_alice;
1810
1811SET SESSION AUTHORIZATION regress_rls_alice;
1812CREATE FUNCTION op_leak(int, int) RETURNS bool
1813    AS 'BEGIN RAISE NOTICE ''op_leak => %, %'', $1, $2; RETURN $1 < $2; END'
1814    LANGUAGE plpgsql;
1815CREATE OPERATOR <<< (procedure = op_leak, leftarg = int, rightarg = int,
1816                     restrict = scalarltsel);
1817SELECT * FROM rls_tbl WHERE a <<< 1000;
1818DROP OPERATOR <<< (int, int);
1819DROP FUNCTION op_leak(int, int);
1820RESET SESSION AUTHORIZATION;
1821DROP TABLE rls_tbl;
1822
1823-- Bug #16006: whole-row Vars in a policy don't play nice with sub-selects
1824SET SESSION AUTHORIZATION regress_rls_alice;
1825CREATE TABLE rls_tbl (a int, b int, c int);
1826CREATE POLICY p1 ON rls_tbl USING (rls_tbl >= ROW(1,1,1));
1827
1828ALTER TABLE rls_tbl ENABLE ROW LEVEL SECURITY;
1829ALTER TABLE rls_tbl FORCE ROW LEVEL SECURITY;
1830
1831INSERT INTO rls_tbl SELECT 10, 20, 30;
1832EXPLAIN (VERBOSE, COSTS OFF)
1833INSERT INTO rls_tbl
1834  SELECT * FROM (SELECT b, c FROM rls_tbl ORDER BY a) ss;
1835INSERT INTO rls_tbl
1836  SELECT * FROM (SELECT b, c FROM rls_tbl ORDER BY a) ss;
1837SELECT * FROM rls_tbl;
1838
1839DROP TABLE rls_tbl;
1840RESET SESSION AUTHORIZATION;
1841
1842--
1843-- Clean up objects
1844--
1845RESET SESSION AUTHORIZATION;
1846
1847DROP SCHEMA regress_rls_schema CASCADE;
1848
1849DROP USER regress_rls_alice;
1850DROP USER regress_rls_bob;
1851DROP USER regress_rls_carol;
1852DROP USER regress_rls_dave;
1853DROP USER regress_rls_exempt_user;
1854DROP ROLE regress_rls_group1;
1855DROP ROLE regress_rls_group2;
1856
1857-- Arrange to have a few policies left over, for testing
1858-- pg_dump/pg_restore
1859CREATE SCHEMA regress_rls_schema;
1860CREATE TABLE rls_tbl (c1 int);
1861ALTER TABLE rls_tbl ENABLE ROW LEVEL SECURITY;
1862CREATE POLICY p1 ON rls_tbl USING (c1 > 5);
1863CREATE POLICY p2 ON rls_tbl FOR SELECT USING (c1 <= 3);
1864CREATE POLICY p3 ON rls_tbl FOR UPDATE USING (c1 <= 3) WITH CHECK (c1 > 5);
1865CREATE POLICY p4 ON rls_tbl FOR DELETE USING (c1 <= 3);
1866
1867CREATE TABLE rls_tbl_force (c1 int);
1868ALTER TABLE rls_tbl_force ENABLE ROW LEVEL SECURITY;
1869ALTER TABLE rls_tbl_force FORCE ROW LEVEL SECURITY;
1870CREATE POLICY p1 ON rls_tbl_force USING (c1 = 5) WITH CHECK (c1 < 5);
1871CREATE POLICY p2 ON rls_tbl_force FOR SELECT USING (c1 = 8);
1872CREATE POLICY p3 ON rls_tbl_force FOR UPDATE USING (c1 = 8) WITH CHECK (c1 >= 5);
1873CREATE POLICY p4 ON rls_tbl_force FOR DELETE USING (c1 = 8);
1874