2 -- Test access privileges
5 -- Clean up in case a prior regression run failed
7 -- Suppress NOTICE messages when users/groups don't exist
8 SET client_min_messages TO 'warning';
10 DROP ROLE IF EXISTS regress_priv_group1;
11 DROP ROLE IF EXISTS regress_priv_group2;
13 DROP ROLE IF EXISTS regress_priv_user1;
14 DROP ROLE IF EXISTS regress_priv_user2;
15 DROP ROLE IF EXISTS regress_priv_user3;
16 DROP ROLE IF EXISTS regress_priv_user4;
17 DROP ROLE IF EXISTS regress_priv_user5;
18 DROP ROLE IF EXISTS regress_priv_user6;
19 DROP ROLE IF EXISTS regress_priv_user7;
21 SELECT lo_unlink(oid) FROM pg_largeobject_metadata WHERE oid >= 1000 AND oid < 3000 ORDER BY oid;
23 RESET client_min_messages;
25 -- test proper begins here
27 CREATE USER regress_priv_user1;
28 CREATE USER regress_priv_user2;
29 CREATE USER regress_priv_user3;
30 CREATE USER regress_priv_user4;
31 CREATE USER regress_priv_user5;
32 CREATE USER regress_priv_user5; -- duplicate
33 CREATE USER regress_priv_user6;
34 CREATE USER regress_priv_user7;
35 CREATE USER regress_priv_user8;
36 CREATE USER regress_priv_user9;
37 CREATE USER regress_priv_user10;
38 CREATE ROLE regress_priv_role;
40 -- circular ADMIN OPTION grants should be disallowed
41 GRANT regress_priv_user1 TO regress_priv_user2 WITH ADMIN OPTION;
42 GRANT regress_priv_user1 TO regress_priv_user3 WITH ADMIN OPTION GRANTED BY regress_priv_user2;
43 GRANT regress_priv_user1 TO regress_priv_user2 WITH ADMIN OPTION GRANTED BY regress_priv_user3;
45 -- need CASCADE to revoke grant or admin option if dependent grants exist
46 REVOKE ADMIN OPTION FOR regress_priv_user1 FROM regress_priv_user2; -- fail
47 REVOKE regress_priv_user1 FROM regress_priv_user2; -- fail
48 SELECT member::regrole, admin_option FROM pg_auth_members WHERE roleid = 'regress_priv_user1'::regrole;
50 REVOKE ADMIN OPTION FOR regress_priv_user1 FROM regress_priv_user2 CASCADE;
51 SELECT member::regrole, admin_option FROM pg_auth_members WHERE roleid = 'regress_priv_user1'::regrole;
53 REVOKE regress_priv_user1 FROM regress_priv_user2 CASCADE;
54 SELECT member::regrole, admin_option FROM pg_auth_members WHERE roleid = 'regress_priv_user1'::regrole;
56 -- inferred grantor must be a role with ADMIN OPTION
57 GRANT regress_priv_user1 TO regress_priv_user2 WITH ADMIN OPTION;
58 GRANT regress_priv_user2 TO regress_priv_user3;
59 SET ROLE regress_priv_user3;
60 GRANT regress_priv_user1 TO regress_priv_user4;
61 SELECT grantor::regrole FROM pg_auth_members WHERE roleid = 'regress_priv_user1'::regrole and member = 'regress_priv_user4'::regrole;
63 REVOKE regress_priv_user2 FROM regress_priv_user3;
64 REVOKE regress_priv_user1 FROM regress_priv_user2 CASCADE;
66 -- test GRANTED BY with DROP OWNED and REASSIGN OWNED
67 GRANT regress_priv_user1 TO regress_priv_user2 WITH ADMIN OPTION;
68 GRANT regress_priv_user1 TO regress_priv_user3 GRANTED BY regress_priv_user2;
69 DROP ROLE regress_priv_user2; -- fail, dependency
70 REASSIGN OWNED BY regress_priv_user2 TO regress_priv_user4;
71 DROP ROLE regress_priv_user2; -- still fail, REASSIGN OWNED doesn't help
72 DROP OWNED BY regress_priv_user2;
73 DROP ROLE regress_priv_user2; -- ok now, DROP OWNED does the job
75 -- test that removing granted role or grantee role removes dependency
76 GRANT regress_priv_user1 TO regress_priv_user3 WITH ADMIN OPTION;
77 GRANT regress_priv_user1 TO regress_priv_user4 GRANTED BY regress_priv_user3;
78 DROP ROLE regress_priv_user3; -- should fail, dependency
79 DROP ROLE regress_priv_user4; -- ok
80 DROP ROLE regress_priv_user3; -- ok now
81 GRANT regress_priv_user1 TO regress_priv_user5 WITH ADMIN OPTION;
82 GRANT regress_priv_user1 TO regress_priv_user6 GRANTED BY regress_priv_user5;
83 DROP ROLE regress_priv_user5; -- should fail, dependency
84 DROP ROLE regress_priv_user1, regress_priv_user5; -- ok, despite order
86 -- recreate the roles we just dropped
87 CREATE USER regress_priv_user1;
88 CREATE USER regress_priv_user2;
89 CREATE USER regress_priv_user3;
90 CREATE USER regress_priv_user4;
91 CREATE USER regress_priv_user5;
93 GRANT pg_read_all_data TO regress_priv_user6;
94 GRANT pg_write_all_data TO regress_priv_user7;
95 GRANT pg_read_all_settings TO regress_priv_user8 WITH ADMIN OPTION;
96 GRANT regress_priv_user9 TO regress_priv_user8;
98 SET SESSION AUTHORIZATION regress_priv_user8;
99 GRANT pg_read_all_settings TO regress_priv_user9 WITH ADMIN OPTION;
101 SET SESSION AUTHORIZATION regress_priv_user9;
102 GRANT pg_read_all_settings TO regress_priv_user10;
104 SET SESSION AUTHORIZATION regress_priv_user8;
105 REVOKE pg_read_all_settings FROM regress_priv_user10 GRANTED BY regress_priv_user9;
106 REVOKE ADMIN OPTION FOR pg_read_all_settings FROM regress_priv_user9;
107 REVOKE pg_read_all_settings FROM regress_priv_user9;
109 RESET SESSION AUTHORIZATION;
110 REVOKE regress_priv_user9 FROM regress_priv_user8;
111 REVOKE ADMIN OPTION FOR pg_read_all_settings FROM regress_priv_user8;
113 SET SESSION AUTHORIZATION regress_priv_user8;
114 SET ROLE pg_read_all_settings;
117 RESET SESSION AUTHORIZATION;
118 REVOKE SET OPTION FOR pg_read_all_settings FROM regress_priv_user8;
119 GRANT pg_read_all_stats TO regress_priv_user8 WITH SET FALSE;
121 SET SESSION AUTHORIZATION regress_priv_user8;
122 SET ROLE pg_read_all_settings; -- fail, no SET option any more
123 SET ROLE pg_read_all_stats; -- fail, granted without SET option
126 RESET SESSION AUTHORIZATION;
127 REVOKE pg_read_all_settings FROM regress_priv_user8;
129 DROP USER regress_priv_user10;
130 DROP USER regress_priv_user9;
131 DROP USER regress_priv_user8;
133 CREATE GROUP regress_priv_group1;
134 CREATE GROUP regress_priv_group2 WITH ADMIN regress_priv_user1 USER regress_priv_user2;
136 ALTER GROUP regress_priv_group1 ADD USER regress_priv_user4;
138 GRANT regress_priv_group2 TO regress_priv_user2 GRANTED BY regress_priv_user1;
139 SET SESSION AUTHORIZATION regress_priv_user1;
140 ALTER GROUP regress_priv_group2 ADD USER regress_priv_user2;
141 ALTER GROUP regress_priv_group2 ADD USER regress_priv_user2; -- duplicate
142 ALTER GROUP regress_priv_group2 DROP USER regress_priv_user2;
143 ALTER USER regress_priv_user2 PASSWORD 'verysecret'; -- not permitted
144 RESET SESSION AUTHORIZATION;
145 ALTER GROUP regress_priv_group2 DROP USER regress_priv_user2;
146 REVOKE ADMIN OPTION FOR regress_priv_group2 FROM regress_priv_user1;
147 GRANT regress_priv_group2 TO regress_priv_user4 WITH ADMIN OPTION;
149 -- prepare non-leakproof function for later
150 CREATE FUNCTION leak(integer,integer) RETURNS boolean
152 LANGUAGE internal IMMUTABLE STRICT; -- but deliberately not LEAKPROOF
153 ALTER FUNCTION leak(integer,integer) OWNER TO regress_priv_user1;
155 -- test owner privileges
157 GRANT regress_priv_role TO regress_priv_user1 WITH ADMIN OPTION GRANTED BY regress_priv_role; -- error, doesn't have ADMIN OPTION
158 GRANT regress_priv_role TO regress_priv_user1 WITH ADMIN OPTION GRANTED BY CURRENT_ROLE;
159 REVOKE ADMIN OPTION FOR regress_priv_role FROM regress_priv_user1 GRANTED BY foo; -- error
160 REVOKE ADMIN OPTION FOR regress_priv_role FROM regress_priv_user1 GRANTED BY regress_priv_user2; -- warning, noop
161 REVOKE ADMIN OPTION FOR regress_priv_role FROM regress_priv_user1 GRANTED BY CURRENT_USER;
162 REVOKE regress_priv_role FROM regress_priv_user1 GRANTED BY CURRENT_ROLE;
163 DROP ROLE regress_priv_role;
165 SET SESSION AUTHORIZATION regress_priv_user1;
166 SELECT session_user, current_user;
168 CREATE TABLE atest1 ( a int, b text );
169 SELECT * FROM atest1;
170 INSERT INTO atest1 VALUES (1, 'one');
172 UPDATE atest1 SET a = 1 WHERE b = 'blech';
175 LOCK atest1 IN ACCESS EXCLUSIVE MODE;
178 REVOKE ALL ON atest1 FROM PUBLIC;
179 SELECT * FROM atest1;
181 GRANT ALL ON atest1 TO regress_priv_user2;
182 GRANT SELECT ON atest1 TO regress_priv_user3, regress_priv_user4;
183 SELECT * FROM atest1;
185 CREATE TABLE atest2 (col1 varchar(10), col2 boolean);
186 SELECT pg_get_acl('pg_class'::regclass, 'atest2'::regclass::oid, 0);
187 GRANT SELECT ON atest2 TO regress_priv_user2;
188 GRANT UPDATE ON atest2 TO regress_priv_user3;
189 GRANT INSERT ON atest2 TO regress_priv_user4 GRANTED BY CURRENT_USER;
190 GRANT TRUNCATE ON atest2 TO regress_priv_user5 GRANTED BY CURRENT_ROLE;
191 SELECT unnest(pg_get_acl('pg_class'::regclass, 'atest2'::regclass::oid, 0));
194 SELECT pg_get_acl('pg_class'::regclass, 0, 0); -- null
195 SELECT pg_get_acl(0, 0, 0); -- null
197 GRANT TRUNCATE ON atest2 TO regress_priv_user4 GRANTED BY regress_priv_user5; -- error
200 SET SESSION AUTHORIZATION regress_priv_user2;
201 SELECT session_user, current_user;
203 -- try various combinations of queries on atest1 and atest2
205 SELECT * FROM atest1; -- ok
206 SELECT * FROM atest2; -- ok
207 INSERT INTO atest1 VALUES (2, 'two'); -- ok
208 INSERT INTO atest2 VALUES ('foo', true); -- fail
209 INSERT INTO atest1 SELECT 1, b FROM atest1; -- ok
210 UPDATE atest1 SET a = 1 WHERE a = 2; -- ok
211 UPDATE atest2 SET col2 = NOT col2; -- fail
212 SELECT * FROM atest1 FOR UPDATE; -- ok
213 SELECT * FROM atest2 FOR UPDATE; -- fail
214 DELETE FROM atest2; -- fail
215 TRUNCATE atest2; -- fail
217 LOCK atest2 IN ACCESS EXCLUSIVE MODE; -- fail
219 COPY atest2 FROM stdin; -- fail
220 GRANT ALL ON atest1 TO PUBLIC; -- fail
222 -- checks in subquery, both ok
223 SELECT * FROM atest1 WHERE ( b IN ( SELECT col1 FROM atest2 ) );
224 SELECT * FROM atest2 WHERE ( col1 IN ( SELECT b FROM atest1 ) );
226 SET SESSION AUTHORIZATION regress_priv_user6;
227 SELECT * FROM atest1; -- ok
228 SELECT * FROM atest2; -- ok
229 INSERT INTO atest2 VALUES ('foo', true); -- fail
231 SET SESSION AUTHORIZATION regress_priv_user7;
232 SELECT * FROM atest1; -- fail
233 SELECT * FROM atest2; -- fail
234 INSERT INTO atest2 VALUES ('foo', true); -- ok
235 UPDATE atest2 SET col2 = true; -- ok
236 DELETE FROM atest2; -- ok
238 -- Make sure we are not able to modify system catalogs
239 UPDATE pg_catalog.pg_class SET relname = '123'; -- fail
240 DELETE FROM pg_catalog.pg_class; -- fail
241 UPDATE pg_toast.pg_toast_1213 SET chunk_id = 1; -- fail
243 SET SESSION AUTHORIZATION regress_priv_user3;
244 SELECT session_user, current_user;
246 SELECT * FROM atest1; -- ok
247 SELECT * FROM atest2; -- fail
248 INSERT INTO atest1 VALUES (2, 'two'); -- fail
249 INSERT INTO atest2 VALUES ('foo', true); -- fail
250 INSERT INTO atest1 SELECT 1, b FROM atest1; -- fail
251 UPDATE atest1 SET a = 1 WHERE a = 2; -- fail
252 UPDATE atest2 SET col2 = NULL; -- ok
253 UPDATE atest2 SET col2 = NOT col2; -- fails; requires SELECT on atest2
254 UPDATE atest2 SET col2 = true FROM atest1 WHERE atest1.a = 5; -- ok
255 SELECT * FROM atest1 FOR UPDATE; -- fail
256 SELECT * FROM atest2 FOR UPDATE; -- fail
257 DELETE FROM atest2; -- fail
258 TRUNCATE atest2; -- fail
260 LOCK atest2 IN ACCESS EXCLUSIVE MODE; -- ok
262 COPY atest2 FROM stdin; -- fail
264 -- checks in subquery, both fail
265 SELECT * FROM atest1 WHERE ( b IN ( SELECT col1 FROM atest2 ) );
266 SELECT * FROM atest2 WHERE ( col1 IN ( SELECT b FROM atest1 ) );
268 SET SESSION AUTHORIZATION regress_priv_user4;
269 COPY atest2 FROM stdin; -- ok
272 SELECT * FROM atest1; -- ok
275 -- test leaky-function protections in selfuncs
277 -- regress_priv_user1 will own a table and provide views for it.
278 SET SESSION AUTHORIZATION regress_priv_user1;
280 CREATE TABLE atest12 as
281 SELECT x AS a, 10001 - x AS b FROM generate_series(1,10000) x;
282 CREATE INDEX ON atest12 (a);
283 CREATE INDEX ON atest12 (abs(a));
284 -- results below depend on having quite accurate stats for atest12, so...
285 ALTER TABLE atest12 SET (autovacuum_enabled = off);
286 SET default_statistics_target = 10000;
287 VACUUM ANALYZE atest12;
288 RESET default_statistics_target;
290 CREATE OPERATOR <<< (procedure = leak, leftarg = integer, rightarg = integer,
291 restrict = scalarltsel);
293 -- views with leaky operator
294 CREATE VIEW atest12v AS
295 SELECT * FROM atest12 WHERE b <<< 5;
296 CREATE VIEW atest12sbv WITH (security_barrier=true) AS
297 SELECT * FROM atest12 WHERE b <<< 5;
298 GRANT SELECT ON atest12v TO PUBLIC;
299 GRANT SELECT ON atest12sbv TO PUBLIC;
301 -- This plan should use nestloop, knowing that few rows will be selected.
302 EXPLAIN (COSTS OFF) SELECT * FROM atest12v x, atest12v y WHERE x.a = y.b;
305 EXPLAIN (COSTS OFF) SELECT * FROM atest12 x, atest12 y
306 WHERE x.a = y.b and abs(y.a) <<< 5;
308 -- This should also be a nestloop, but the security barrier forces the inner
309 -- scan to be materialized
310 EXPLAIN (COSTS OFF) SELECT * FROM atest12sbv x, atest12sbv y WHERE x.a = y.b;
312 -- Check if regress_priv_user2 can break security.
313 SET SESSION AUTHORIZATION regress_priv_user2;
315 CREATE FUNCTION leak2(integer,integer) RETURNS boolean
316 AS $$begin raise notice 'leak % %', $1, $2; return $1 > $2; end$$
317 LANGUAGE plpgsql immutable;
318 CREATE OPERATOR >>> (procedure = leak2, leftarg = integer, rightarg = integer,
319 restrict = scalargtsel);
321 -- This should not show any "leak" notices before failing.
322 EXPLAIN (COSTS OFF) SELECT * FROM atest12 WHERE a >>> 0;
324 -- These plans should continue to use a nestloop, since they execute with the
325 -- privileges of the view owner.
326 EXPLAIN (COSTS OFF) SELECT * FROM atest12v x, atest12v y WHERE x.a = y.b;
327 EXPLAIN (COSTS OFF) SELECT * FROM atest12sbv x, atest12sbv y WHERE x.a = y.b;
329 -- A non-security barrier view does not guard against information leakage.
330 EXPLAIN (COSTS OFF) SELECT * FROM atest12v x, atest12v y
331 WHERE x.a = y.b and abs(y.a) <<< 5;
333 -- But a security barrier view isolates the leaky operator.
334 EXPLAIN (COSTS OFF) SELECT * FROM atest12sbv x, atest12sbv y
335 WHERE x.a = y.b and abs(y.a) <<< 5;
337 -- Now regress_priv_user1 grants sufficient access to regress_priv_user2.
338 SET SESSION AUTHORIZATION regress_priv_user1;
339 GRANT SELECT (a, b) ON atest12 TO PUBLIC;
340 SET SESSION AUTHORIZATION regress_priv_user2;
342 -- regress_priv_user2 should continue to get a good row estimate.
343 EXPLAIN (COSTS OFF) SELECT * FROM atest12v x, atest12v y WHERE x.a = y.b;
345 -- But not for this, due to lack of table-wide permissions needed
346 -- to make use of the expression index's statistics.
347 EXPLAIN (COSTS OFF) SELECT * FROM atest12 x, atest12 y
348 WHERE x.a = y.b and abs(y.a) <<< 5;
350 -- clean up (regress_priv_user1's objects are all dropped later)
351 DROP FUNCTION leak2(integer, integer) CASCADE;
356 SET SESSION AUTHORIZATION regress_priv_user3;
357 CREATE TABLE atest3 (one int, two int, three int);
358 GRANT DELETE ON atest3 TO GROUP regress_priv_group2;
360 SET SESSION AUTHORIZATION regress_priv_user1;
362 SELECT * FROM atest3; -- fail
363 DELETE FROM atest3; -- ok
366 RESET SESSION AUTHORIZATION;
367 ALTER ROLE regress_priv_user1 NOINHERIT;
368 SET SESSION AUTHORIZATION regress_priv_user1;
370 DELETE FROM atest3; -- ok because grant-level option is unchanged
372 RESET SESSION AUTHORIZATION;
373 GRANT regress_priv_group2 TO regress_priv_user1 WITH INHERIT FALSE;
374 SET SESSION AUTHORIZATION regress_priv_user1;
375 DELETE FROM atest3; -- fail
377 RESET SESSION AUTHORIZATION;
378 REVOKE INHERIT OPTION FOR regress_priv_group2 FROM regress_priv_user1;
379 SET SESSION AUTHORIZATION regress_priv_user1;
380 DELETE FROM atest3; -- also fail
385 SET SESSION AUTHORIZATION regress_priv_user3;
387 CREATE VIEW atestv1 AS SELECT * FROM atest1; -- ok
388 /* The next *should* fail, but it's not implemented that way yet. */
389 CREATE VIEW atestv2 AS SELECT * FROM atest2;
390 CREATE VIEW atestv3 AS SELECT * FROM atest3; -- ok
391 /* Empty view is a corner case that failed in 9.2. */
392 CREATE VIEW atestv0 AS SELECT 0 as x WHERE false; -- ok
394 SELECT * FROM atestv1; -- ok
395 SELECT * FROM atestv2; -- fail
396 GRANT SELECT ON atestv1, atestv3 TO regress_priv_user4;
397 GRANT SELECT ON atestv2 TO regress_priv_user2;
399 SET SESSION AUTHORIZATION regress_priv_user4;
401 SELECT * FROM atestv1; -- ok
402 SELECT * FROM atestv2; -- fail
403 SELECT * FROM atestv3; -- ok
404 SELECT * FROM atestv0; -- fail
406 -- Appendrels excluded by constraints failed to check permissions in 8.4-9.2.
408 ((select a.q1 as x from int8_tbl a offset 0)
410 (select b.q2 as x from int8_tbl b offset 0)) ss
413 set constraint_exclusion = on;
415 ((select a.q1 as x, random() from int8_tbl a where q1 > 0)
417 (select b.q2 as x, random() from int8_tbl b where q2 > 0)) ss
419 reset constraint_exclusion;
421 CREATE VIEW atestv4 AS SELECT * FROM atestv3; -- nested view
422 SELECT * FROM atestv4; -- ok
423 GRANT SELECT ON atestv4 TO regress_priv_user2;
425 SET SESSION AUTHORIZATION regress_priv_user2;
427 -- Two complex cases:
429 SELECT * FROM atestv3; -- fail
430 SELECT * FROM atestv4; -- ok (even though regress_priv_user2 cannot access underlying atestv3)
432 SELECT * FROM atest2; -- ok
433 SELECT * FROM atestv2; -- fail (even though regress_priv_user2 can access underlying atest2)
435 -- Test column level permissions
437 SET SESSION AUTHORIZATION regress_priv_user1;
438 CREATE TABLE atest5 (one int, two int unique, three int, four int unique);
439 CREATE TABLE atest6 (one int, two int, blue int);
440 GRANT SELECT (one), INSERT (two), UPDATE (three) ON atest5 TO regress_priv_user4;
441 GRANT ALL (one) ON atest5 TO regress_priv_user3;
442 SELECT unnest(pg_get_acl('pg_class'::regclass, 'atest5'::regclass::oid, 1));
443 SELECT unnest(pg_get_acl('pg_class'::regclass, 'atest5'::regclass::oid, 2));
444 SELECT unnest(pg_get_acl('pg_class'::regclass, 'atest5'::regclass::oid, 3));
445 SELECT unnest(pg_get_acl('pg_class'::regclass, 'atest5'::regclass::oid, 4));
447 INSERT INTO atest5 VALUES (1,2,3);
449 SET SESSION AUTHORIZATION regress_priv_user4;
450 SELECT * FROM atest5; -- fail
451 SELECT one FROM atest5; -- ok
452 COPY atest5 (one) TO stdout; -- ok
453 SELECT two FROM atest5; -- fail
454 COPY atest5 (two) TO stdout; -- fail
455 SELECT atest5 FROM atest5; -- fail
456 COPY atest5 (one,two) TO stdout; -- fail
457 SELECT 1 FROM atest5; -- ok
458 SELECT 1 FROM atest5 a JOIN atest5 b USING (one); -- ok
459 SELECT 1 FROM atest5 a JOIN atest5 b USING (two); -- fail
460 SELECT 1 FROM atest5 a NATURAL JOIN atest5 b; -- fail
461 SELECT * FROM (atest5 a JOIN atest5 b USING (one)) j; -- fail
462 SELECT j.* FROM (atest5 a JOIN atest5 b USING (one)) j; -- fail
463 SELECT (j.*) IS NULL FROM (atest5 a JOIN atest5 b USING (one)) j; -- fail
464 SELECT one FROM (atest5 a JOIN atest5 b(one,x,y,z) USING (one)) j; -- ok
465 SELECT j.one FROM (atest5 a JOIN atest5 b(one,x,y,z) USING (one)) j; -- ok
466 SELECT two FROM (atest5 a JOIN atest5 b(one,x,y,z) USING (one)) j; -- fail
467 SELECT j.two FROM (atest5 a JOIN atest5 b(one,x,y,z) USING (one)) j; -- fail
468 SELECT y FROM (atest5 a JOIN atest5 b(one,x,y,z) USING (one)) j; -- fail
469 SELECT j.y FROM (atest5 a JOIN atest5 b(one,x,y,z) USING (one)) j; -- fail
470 SELECT * FROM (atest5 a JOIN atest5 b USING (one)); -- fail
471 SELECT a.* FROM (atest5 a JOIN atest5 b USING (one)); -- fail
472 SELECT (a.*) IS NULL FROM (atest5 a JOIN atest5 b USING (one)); -- fail
473 SELECT two FROM (atest5 a JOIN atest5 b(one,x,y,z) USING (one)); -- fail
474 SELECT a.two FROM (atest5 a JOIN atest5 b(one,x,y,z) USING (one)); -- fail
475 SELECT y FROM (atest5 a JOIN atest5 b(one,x,y,z) USING (one)); -- fail
476 SELECT b.y FROM (atest5 a JOIN atest5 b(one,x,y,z) USING (one)); -- fail
477 SELECT y FROM (atest5 a LEFT JOIN atest5 b(one,x,y,z) USING (one)); -- fail
478 SELECT b.y FROM (atest5 a LEFT JOIN atest5 b(one,x,y,z) USING (one)); -- fail
479 SELECT y FROM (atest5 a FULL JOIN atest5 b(one,x,y,z) USING (one)); -- fail
480 SELECT b.y FROM (atest5 a FULL JOIN atest5 b(one,x,y,z) USING (one)); -- fail
481 SELECT 1 FROM atest5 WHERE two = 2; -- fail
482 SELECT * FROM atest1, atest5; -- fail
483 SELECT atest1.* FROM atest1, atest5; -- ok
484 SELECT atest1.*,atest5.one FROM atest1, atest5; -- ok
485 SELECT atest1.*,atest5.one FROM atest1 JOIN atest5 ON (atest1.a = atest5.two); -- fail
486 SELECT atest1.*,atest5.one FROM atest1 JOIN atest5 ON (atest1.a = atest5.one); -- ok
487 SELECT one, two FROM atest5; -- fail
489 SET SESSION AUTHORIZATION regress_priv_user1;
490 GRANT SELECT (one,two) ON atest6 TO regress_priv_user4;
492 SET SESSION AUTHORIZATION regress_priv_user4;
493 SELECT one, two FROM atest5 NATURAL JOIN atest6; -- fail still
495 SET SESSION AUTHORIZATION regress_priv_user1;
496 GRANT SELECT (two) ON atest5 TO regress_priv_user4;
498 SET SESSION AUTHORIZATION regress_priv_user4;
499 SELECT one, two FROM atest5 NATURAL JOIN atest6; -- ok now
501 -- test column-level privileges for INSERT and UPDATE
502 INSERT INTO atest5 (two) VALUES (3); -- ok
503 COPY atest5 FROM stdin; -- fail
504 COPY atest5 (two) FROM stdin; -- ok
507 INSERT INTO atest5 (three) VALUES (4); -- fail
508 INSERT INTO atest5 VALUES (5,5,5); -- fail
509 UPDATE atest5 SET three = 10; -- ok
510 UPDATE atest5 SET one = 8; -- fail
511 UPDATE atest5 SET three = 5, one = 2; -- fail
512 -- Check that column level privs are enforced in RETURNING
514 INSERT INTO atest5(two) VALUES (6) ON CONFLICT (two) DO UPDATE set three = 10;
515 -- Error. No SELECT on column three.
516 INSERT INTO atest5(two) VALUES (6) ON CONFLICT (two) DO UPDATE set three = 10 RETURNING atest5.three;
517 -- Ok. May SELECT on column "one":
518 INSERT INTO atest5(two) VALUES (6) ON CONFLICT (two) DO UPDATE set three = 10 RETURNING atest5.one;
519 -- Check that column level privileges are enforced for EXCLUDED
520 -- Ok. we may select one
521 INSERT INTO atest5(two) VALUES (6) ON CONFLICT (two) DO UPDATE set three = EXCLUDED.one;
522 -- Error. No select rights on three
523 INSERT INTO atest5(two) VALUES (6) ON CONFLICT (two) DO UPDATE set three = EXCLUDED.three;
524 INSERT INTO atest5(two) VALUES (6) ON CONFLICT (two) DO UPDATE set one = 8; -- fails (due to UPDATE)
525 INSERT INTO atest5(three) VALUES (4) ON CONFLICT (two) DO UPDATE set three = 10; -- fails (due to INSERT)
527 -- Check that the columns in the inference require select privileges
528 INSERT INTO atest5(four) VALUES (4); -- fail
530 SET SESSION AUTHORIZATION regress_priv_user1;
531 GRANT INSERT (four) ON atest5 TO regress_priv_user4;
532 SET SESSION AUTHORIZATION regress_priv_user4;
534 INSERT INTO atest5(four) VALUES (4) ON CONFLICT (four) DO UPDATE set three = 3; -- fails (due to SELECT)
535 INSERT INTO atest5(four) VALUES (4) ON CONFLICT ON CONSTRAINT atest5_four_key DO UPDATE set three = 3; -- fails (due to SELECT)
536 INSERT INTO atest5(four) VALUES (4); -- ok
538 SET SESSION AUTHORIZATION regress_priv_user1;
539 GRANT SELECT (four) ON atest5 TO regress_priv_user4;
540 SET SESSION AUTHORIZATION regress_priv_user4;
542 INSERT INTO atest5(four) VALUES (4) ON CONFLICT (four) DO UPDATE set three = 3; -- ok
543 INSERT INTO atest5(four) VALUES (4) ON CONFLICT ON CONSTRAINT atest5_four_key DO UPDATE set three = 3; -- ok
545 SET SESSION AUTHORIZATION regress_priv_user1;
546 REVOKE ALL (one) ON atest5 FROM regress_priv_user4;
547 GRANT SELECT (one,two,blue) ON atest6 TO regress_priv_user4;
549 SET SESSION AUTHORIZATION regress_priv_user4;
550 SELECT one FROM atest5; -- fail
551 UPDATE atest5 SET one = 1; -- fail
552 SELECT atest6 FROM atest6; -- ok
553 COPY atest6 TO stdout; -- ok
555 -- test column privileges with MERGE
556 SET SESSION AUTHORIZATION regress_priv_user1;
557 CREATE TABLE mtarget (a int, b text);
558 CREATE TABLE msource (a int, b text);
559 INSERT INTO mtarget VALUES (1, 'init1'), (2, 'init2');
560 INSERT INTO msource VALUES (1, 'source1'), (2, 'source2'), (3, 'source3');
562 GRANT SELECT (a) ON msource TO regress_priv_user4;
563 GRANT SELECT (a) ON mtarget TO regress_priv_user4;
564 GRANT INSERT (a,b) ON mtarget TO regress_priv_user4;
565 GRANT UPDATE (b) ON mtarget TO regress_priv_user4;
567 SET SESSION AUTHORIZATION regress_priv_user4;
570 -- test source privileges
573 -- fail (no SELECT priv on s.b)
574 MERGE INTO mtarget t USING msource s ON t.a = s.a
577 WHEN NOT MATCHED THEN
578 INSERT VALUES (a, NULL);
580 -- fail (s.b used in the INSERTed values)
581 MERGE INTO mtarget t USING msource s ON t.a = s.a
584 WHEN NOT MATCHED THEN
585 INSERT VALUES (a, b);
587 -- fail (s.b used in the WHEN quals)
588 MERGE INTO mtarget t USING msource s ON t.a = s.a
589 WHEN MATCHED AND s.b = 'x' THEN
591 WHEN NOT MATCHED THEN
592 INSERT VALUES (a, NULL);
594 -- this should be ok since only s.a is accessed
596 MERGE INTO mtarget t USING msource s ON t.a = s.a
599 WHEN NOT MATCHED THEN
600 INSERT VALUES (a, NULL);
603 SET SESSION AUTHORIZATION regress_priv_user1;
604 GRANT SELECT (b) ON msource TO regress_priv_user4;
605 SET SESSION AUTHORIZATION regress_priv_user4;
609 MERGE INTO mtarget t USING msource s ON t.a = s.a
612 WHEN NOT MATCHED THEN
613 INSERT VALUES (a, b);
617 -- test target privileges
620 -- fail (no SELECT priv on t.b)
621 MERGE INTO mtarget t USING msource s ON t.a = s.a
624 WHEN NOT MATCHED THEN
625 INSERT VALUES (a, NULL);
627 -- fail (no UPDATE on t.a)
628 MERGE INTO mtarget t USING msource s ON t.a = s.a
630 UPDATE SET b = s.b, a = t.a + 1
631 WHEN NOT MATCHED THEN
632 INSERT VALUES (a, b);
634 -- fail (no SELECT on t.b)
635 MERGE INTO mtarget t USING msource s ON t.a = s.a
636 WHEN MATCHED AND t.b IS NOT NULL THEN
638 WHEN NOT MATCHED THEN
639 INSERT VALUES (a, b);
643 MERGE INTO mtarget t USING msource s ON t.a = s.a
649 MERGE INTO mtarget t USING msource s ON t.a = s.a
650 WHEN MATCHED AND t.b IS NOT NULL THEN
653 -- grant delete privileges
654 SET SESSION AUTHORIZATION regress_priv_user1;
655 GRANT DELETE ON mtarget TO regress_priv_user4;
658 MERGE INTO mtarget t USING msource s ON t.a = s.a
659 WHEN MATCHED AND t.b IS NOT NULL THEN
663 -- check error reporting with column privs
664 SET SESSION AUTHORIZATION regress_priv_user1;
665 CREATE TABLE t1 (c1 int, c2 int, c3 int check (c3 < 5), primary key (c1, c2));
666 GRANT SELECT (c1) ON t1 TO regress_priv_user2;
667 GRANT INSERT (c1, c2, c3) ON t1 TO regress_priv_user2;
668 GRANT UPDATE (c1, c2, c3) ON t1 TO regress_priv_user2;
671 INSERT INTO t1 VALUES (1, 1, 1);
672 INSERT INTO t1 VALUES (1, 2, 1);
673 INSERT INTO t1 VALUES (2, 1, 2);
674 INSERT INTO t1 VALUES (2, 2, 2);
675 INSERT INTO t1 VALUES (3, 1, 3);
677 SET SESSION AUTHORIZATION regress_priv_user2;
678 INSERT INTO t1 (c1, c2) VALUES (1, 1); -- fail, but row not shown
679 UPDATE t1 SET c2 = 1; -- fail, but row not shown
680 INSERT INTO t1 (c1, c2) VALUES (null, null); -- fail, but see columns being inserted
681 INSERT INTO t1 (c3) VALUES (null); -- fail, but see columns being inserted or have SELECT
682 INSERT INTO t1 (c1) VALUES (5); -- fail, but see columns being inserted or have SELECT
683 UPDATE t1 SET c3 = 10; -- fail, but see columns with SELECT rights, or being modified
685 SET SESSION AUTHORIZATION regress_priv_user1;
688 -- check error reporting with column privs on a partitioned table
689 CREATE TABLE errtst(a text, b text NOT NULL, c text, secret1 text, secret2 text) PARTITION BY LIST (a);
690 CREATE TABLE errtst_part_1(secret2 text, c text, a text, b text NOT NULL, secret1 text);
691 CREATE TABLE errtst_part_2(secret1 text, secret2 text, a text, c text, b text NOT NULL);
693 ALTER TABLE errtst ATTACH PARTITION errtst_part_1 FOR VALUES IN ('aaa');
694 ALTER TABLE errtst ATTACH PARTITION errtst_part_2 FOR VALUES IN ('aaaa');
696 GRANT SELECT (a, b, c) ON TABLE errtst TO regress_priv_user2;
697 GRANT UPDATE (a, b, c) ON TABLE errtst TO regress_priv_user2;
698 GRANT INSERT (a, b, c) ON TABLE errtst TO regress_priv_user2;
700 INSERT INTO errtst_part_1 (a, b, c, secret1, secret2)
701 VALUES ('aaa', 'bbb', 'ccc', 'the body', 'is in the attic');
703 SET SESSION AUTHORIZATION regress_priv_user2;
705 -- Perform a few updates that violate the NOT NULL constraint. Make sure
706 -- the error messages don't leak the secret fields.
709 INSERT INTO errtst (a, b) VALUES ('aaa', NULL);
711 UPDATE errtst SET b = NULL;
712 -- partitioning key is updated, doesn't move the row.
713 UPDATE errtst SET a = 'aaa', b = NULL;
714 -- row is moved to another partition.
715 UPDATE errtst SET a = 'aaaa', b = NULL;
717 -- row is moved to another partition. This differs from the previous case in
718 -- that the new partition is excluded by constraint exclusion, so its
719 -- ResultRelInfo is not created at ExecInitModifyTable, but needs to be
720 -- constructed on the fly when the updated tuple is routed to it.
721 UPDATE errtst SET a = 'aaaa', b = NULL WHERE a = 'aaa';
723 SET SESSION AUTHORIZATION regress_priv_user1;
726 -- test column-level privileges when involved with DELETE
727 SET SESSION AUTHORIZATION regress_priv_user1;
728 ALTER TABLE atest6 ADD COLUMN three integer;
729 GRANT DELETE ON atest5 TO regress_priv_user3;
730 GRANT SELECT (two) ON atest5 TO regress_priv_user3;
731 REVOKE ALL (one) ON atest5 FROM regress_priv_user3;
732 GRANT SELECT (one) ON atest5 TO regress_priv_user4;
734 SET SESSION AUTHORIZATION regress_priv_user4;
735 SELECT atest6 FROM atest6; -- fail
736 SELECT one FROM atest5 NATURAL JOIN atest6; -- fail
738 SET SESSION AUTHORIZATION regress_priv_user1;
739 ALTER TABLE atest6 DROP COLUMN three;
741 SET SESSION AUTHORIZATION regress_priv_user4;
742 SELECT atest6 FROM atest6; -- ok
743 SELECT one FROM atest5 NATURAL JOIN atest6; -- ok
745 SET SESSION AUTHORIZATION regress_priv_user1;
746 ALTER TABLE atest6 DROP COLUMN two;
747 REVOKE SELECT (one,blue) ON atest6 FROM regress_priv_user4;
749 SET SESSION AUTHORIZATION regress_priv_user4;
750 SELECT * FROM atest6; -- fail
751 SELECT 1 FROM atest6; -- fail
753 SET SESSION AUTHORIZATION regress_priv_user3;
754 DELETE FROM atest5 WHERE one = 1; -- fail
755 DELETE FROM atest5 WHERE two = 2; -- ok
757 -- check inheritance cases
758 SET SESSION AUTHORIZATION regress_priv_user1;
759 CREATE TABLE atestp1 (f1 int, f2 int);
760 CREATE TABLE atestp2 (fx int, fy int);
761 CREATE TABLE atestc (fz int) INHERITS (atestp1, atestp2);
762 GRANT SELECT(fx,fy,tableoid) ON atestp2 TO regress_priv_user2;
763 GRANT SELECT(fx) ON atestc TO regress_priv_user2;
765 SET SESSION AUTHORIZATION regress_priv_user2;
766 SELECT fx FROM atestp2; -- ok
767 SELECT fy FROM atestp2; -- ok
768 SELECT atestp2 FROM atestp2; -- ok
769 SELECT tableoid FROM atestp2; -- ok
770 SELECT fy FROM atestc; -- fail
772 SET SESSION AUTHORIZATION regress_priv_user1;
773 GRANT SELECT(fy,tableoid) ON atestc TO regress_priv_user2;
775 SET SESSION AUTHORIZATION regress_priv_user2;
776 SELECT fx FROM atestp2; -- still ok
777 SELECT fy FROM atestp2; -- ok
778 SELECT atestp2 FROM atestp2; -- ok
779 SELECT tableoid FROM atestp2; -- ok
781 -- child's permissions do not apply when operating on parent
782 SET SESSION AUTHORIZATION regress_priv_user1;
783 REVOKE ALL ON atestc FROM regress_priv_user2;
784 GRANT ALL ON atestp1 TO regress_priv_user2;
785 SET SESSION AUTHORIZATION regress_priv_user2;
786 SELECT f2 FROM atestp1; -- ok
787 SELECT f2 FROM atestc; -- fail
788 DELETE FROM atestp1; -- ok
789 DELETE FROM atestc; -- fail
790 UPDATE atestp1 SET f1 = 1; -- ok
791 UPDATE atestc SET f1 = 1; -- fail
792 TRUNCATE atestp1; -- ok
793 TRUNCATE atestc; -- fail
801 -- privileges on functions, languages
803 -- switch to superuser
806 REVOKE ALL PRIVILEGES ON LANGUAGE sql FROM PUBLIC;
807 GRANT USAGE ON LANGUAGE sql TO regress_priv_user1; -- ok
808 GRANT USAGE ON LANGUAGE c TO PUBLIC; -- fail
810 SET SESSION AUTHORIZATION regress_priv_user1;
811 GRANT USAGE ON LANGUAGE sql TO regress_priv_user2; -- fail
812 CREATE FUNCTION priv_testfunc1(int) RETURNS int AS 'select 2 * $1;' LANGUAGE sql;
813 CREATE FUNCTION priv_testfunc2(int) RETURNS int AS 'select 3 * $1;' LANGUAGE sql;
814 CREATE AGGREGATE priv_testagg1(int) (sfunc = int4pl, stype = int4);
815 CREATE PROCEDURE priv_testproc1(int) AS 'select $1;' LANGUAGE sql;
817 REVOKE ALL ON FUNCTION priv_testfunc1(int), priv_testfunc2(int), priv_testagg1(int) FROM PUBLIC;
818 GRANT EXECUTE ON FUNCTION priv_testfunc1(int), priv_testfunc2(int), priv_testagg1(int) TO regress_priv_user2;
819 REVOKE ALL ON FUNCTION priv_testproc1(int) FROM PUBLIC; -- fail, not a function
820 REVOKE ALL ON PROCEDURE priv_testproc1(int) FROM PUBLIC;
821 GRANT EXECUTE ON PROCEDURE priv_testproc1(int) TO regress_priv_user2;
822 GRANT USAGE ON FUNCTION priv_testfunc1(int) TO regress_priv_user3; -- semantic error
823 GRANT USAGE ON FUNCTION priv_testagg1(int) TO regress_priv_user3; -- semantic error
824 GRANT USAGE ON PROCEDURE priv_testproc1(int) TO regress_priv_user3; -- semantic error
825 GRANT ALL PRIVILEGES ON FUNCTION priv_testfunc1(int) TO regress_priv_user4;
826 GRANT ALL PRIVILEGES ON FUNCTION priv_testfunc_nosuch(int) TO regress_priv_user4;
827 GRANT ALL PRIVILEGES ON FUNCTION priv_testagg1(int) TO regress_priv_user4;
828 GRANT ALL PRIVILEGES ON PROCEDURE priv_testproc1(int) TO regress_priv_user4;
830 CREATE FUNCTION priv_testfunc4(boolean) RETURNS text
831 AS 'select col1 from atest2 where col2 = $1;'
832 LANGUAGE sql SECURITY DEFINER;
833 GRANT EXECUTE ON FUNCTION priv_testfunc4(boolean) TO regress_priv_user3;
835 SET SESSION AUTHORIZATION regress_priv_user2;
836 SELECT priv_testfunc1(5), priv_testfunc2(5); -- ok
837 CREATE FUNCTION priv_testfunc3(int) RETURNS int AS 'select 2 * $1;' LANGUAGE sql; -- fail
838 SELECT priv_testagg1(x) FROM (VALUES (1), (2), (3)) _(x); -- ok
839 CALL priv_testproc1(6); -- ok
841 SET SESSION AUTHORIZATION regress_priv_user3;
842 SELECT priv_testfunc1(5); -- fail
843 SELECT priv_testagg1(x) FROM (VALUES (1), (2), (3)) _(x); -- fail
844 CALL priv_testproc1(6); -- fail
845 SELECT col1 FROM atest2 WHERE col2 = true; -- fail
846 SELECT priv_testfunc4(true); -- ok
848 SET SESSION AUTHORIZATION regress_priv_user4;
849 SELECT priv_testfunc1(5); -- ok
850 SELECT priv_testagg1(x) FROM (VALUES (1), (2), (3)) _(x); -- ok
851 CALL priv_testproc1(6); -- ok
853 DROP FUNCTION priv_testfunc1(int); -- fail
854 DROP AGGREGATE priv_testagg1(int); -- fail
855 DROP PROCEDURE priv_testproc1(int); -- fail
859 DROP FUNCTION priv_testfunc1(int); -- ok
861 GRANT ALL PRIVILEGES ON LANGUAGE sql TO PUBLIC;
863 -- verify privilege checks on array-element coercions
865 SELECT '{1}'::int4[]::int8[];
866 REVOKE ALL ON FUNCTION int8(integer) FROM PUBLIC;
867 SELECT '{1}'::int4[]::int8[]; --superuser, succeed
868 SET SESSION AUTHORIZATION regress_priv_user4;
869 SELECT '{1}'::int4[]::int8[]; --other user, fail
872 -- privileges on types
874 -- switch to superuser
877 CREATE TYPE priv_testtype1 AS (a int, b text);
878 REVOKE USAGE ON TYPE priv_testtype1 FROM PUBLIC;
879 GRANT USAGE ON TYPE priv_testtype1 TO regress_priv_user2;
880 GRANT USAGE ON TYPE _priv_testtype1 TO regress_priv_user2; -- fail
881 GRANT USAGE ON DOMAIN priv_testtype1 TO regress_priv_user2; -- fail
883 CREATE DOMAIN priv_testdomain1 AS int;
884 REVOKE USAGE on DOMAIN priv_testdomain1 FROM PUBLIC;
885 GRANT USAGE ON DOMAIN priv_testdomain1 TO regress_priv_user2;
886 GRANT USAGE ON TYPE priv_testdomain1 TO regress_priv_user2; -- ok
888 SET SESSION AUTHORIZATION regress_priv_user1;
890 -- commands that should fail
892 CREATE AGGREGATE priv_testagg1a(priv_testdomain1) (sfunc = int4_sum, stype = bigint);
894 CREATE DOMAIN priv_testdomain2a AS priv_testdomain1;
896 CREATE DOMAIN priv_testdomain3a AS int;
897 CREATE FUNCTION castfunc(int) RETURNS priv_testdomain3a AS $$ SELECT $1::priv_testdomain3a $$ LANGUAGE SQL;
898 CREATE CAST (priv_testdomain1 AS priv_testdomain3a) WITH FUNCTION castfunc(int);
899 DROP FUNCTION castfunc(int) CASCADE;
900 DROP DOMAIN priv_testdomain3a;
902 CREATE FUNCTION priv_testfunc5a(a priv_testdomain1) RETURNS int LANGUAGE SQL AS $$ SELECT $1 $$;
903 CREATE FUNCTION priv_testfunc6a(b int) RETURNS priv_testdomain1 LANGUAGE SQL AS $$ SELECT $1::priv_testdomain1 $$;
905 CREATE OPERATOR !+! (PROCEDURE = int4pl, LEFTARG = priv_testdomain1, RIGHTARG = priv_testdomain1);
907 CREATE TABLE test5a (a int, b priv_testdomain1);
908 CREATE TABLE test6a OF priv_testtype1;
909 CREATE TABLE test10a (a int[], b priv_testtype1[]);
911 CREATE TABLE test9a (a int, b int);
912 ALTER TABLE test9a ADD COLUMN c priv_testdomain1;
913 ALTER TABLE test9a ALTER COLUMN b TYPE priv_testdomain1;
915 CREATE TYPE test7a AS (a int, b priv_testdomain1);
917 CREATE TYPE test8a AS (a int, b int);
918 ALTER TYPE test8a ADD ATTRIBUTE c priv_testdomain1;
919 ALTER TYPE test8a ALTER ATTRIBUTE b TYPE priv_testdomain1;
921 CREATE TABLE test11a AS (SELECT 1::priv_testdomain1 AS a);
923 REVOKE ALL ON TYPE priv_testtype1 FROM PUBLIC;
925 SET SESSION AUTHORIZATION regress_priv_user2;
927 -- commands that should succeed
929 CREATE AGGREGATE priv_testagg1b(priv_testdomain1) (sfunc = int4_sum, stype = bigint);
931 CREATE DOMAIN priv_testdomain2b AS priv_testdomain1;
933 CREATE DOMAIN priv_testdomain3b AS int;
934 CREATE FUNCTION castfunc(int) RETURNS priv_testdomain3b AS $$ SELECT $1::priv_testdomain3b $$ LANGUAGE SQL;
935 CREATE CAST (priv_testdomain1 AS priv_testdomain3b) WITH FUNCTION castfunc(int);
937 CREATE FUNCTION priv_testfunc5b(a priv_testdomain1) RETURNS int LANGUAGE SQL AS $$ SELECT $1 $$;
938 CREATE FUNCTION priv_testfunc6b(b int) RETURNS priv_testdomain1 LANGUAGE SQL AS $$ SELECT $1::priv_testdomain1 $$;
940 CREATE OPERATOR !! (PROCEDURE = priv_testfunc5b, RIGHTARG = priv_testdomain1);
942 CREATE TABLE test5b (a int, b priv_testdomain1);
943 CREATE TABLE test6b OF priv_testtype1;
944 CREATE TABLE test10b (a int[], b priv_testtype1[]);
946 CREATE TABLE test9b (a int, b int);
947 ALTER TABLE test9b ADD COLUMN c priv_testdomain1;
948 ALTER TABLE test9b ALTER COLUMN b TYPE priv_testdomain1;
950 CREATE TYPE test7b AS (a int, b priv_testdomain1);
952 CREATE TYPE test8b AS (a int, b int);
953 ALTER TYPE test8b ADD ATTRIBUTE c priv_testdomain1;
954 ALTER TYPE test8b ALTER ATTRIBUTE b TYPE priv_testdomain1;
956 CREATE TABLE test11b AS (SELECT 1::priv_testdomain1 AS a);
958 REVOKE ALL ON TYPE priv_testtype1 FROM PUBLIC;
961 DROP AGGREGATE priv_testagg1b(priv_testdomain1);
962 DROP DOMAIN priv_testdomain2b;
963 DROP OPERATOR !! (NONE, priv_testdomain1);
964 DROP FUNCTION priv_testfunc5b(a priv_testdomain1);
965 DROP FUNCTION priv_testfunc6b(b int);
972 DROP CAST (priv_testdomain1 AS priv_testdomain3b);
973 DROP FUNCTION castfunc(int) CASCADE;
974 DROP DOMAIN priv_testdomain3b;
977 DROP TYPE priv_testtype1; -- ok
978 DROP DOMAIN priv_testdomain1; -- ok
982 SET SESSION AUTHORIZATION regress_priv_user5;
983 TRUNCATE atest2; -- ok
984 TRUNCATE atest3; -- fail
986 -- has_table_privilege function
989 select has_table_privilege(NULL,'pg_authid','select');
990 select has_table_privilege('pg_shad','select');
991 select has_table_privilege('nosuchuser','pg_authid','select');
992 select has_table_privilege('pg_authid','sel');
993 select has_table_privilege(-999999,'pg_authid','update');
994 select has_table_privilege(1,'select');
999 select has_table_privilege(current_user,'pg_authid','select');
1000 select has_table_privilege(current_user,'pg_authid','insert');
1002 select has_table_privilege(t2.oid,'pg_authid','update')
1003 from (select oid from pg_roles where rolname = current_user) as t2;
1004 select has_table_privilege(t2.oid,'pg_authid','delete')
1005 from (select oid from pg_roles where rolname = current_user) as t2;
1007 select has_table_privilege(current_user,t1.oid,'references')
1008 from (select oid from pg_class where relname = 'pg_authid') as t1;
1010 select has_table_privilege(t2.oid,t1.oid,'select')
1011 from (select oid from pg_class where relname = 'pg_authid') as t1,
1012 (select oid from pg_roles where rolname = current_user) as t2;
1013 select has_table_privilege(t2.oid,t1.oid,'insert')
1014 from (select oid from pg_class where relname = 'pg_authid') as t1,
1015 (select oid from pg_roles where rolname = current_user) as t2;
1017 select has_table_privilege('pg_authid','update');
1018 select has_table_privilege('pg_authid','delete');
1019 select has_table_privilege('pg_authid','truncate');
1021 select has_table_privilege(t1.oid,'select')
1022 from (select oid from pg_class where relname = 'pg_authid') as t1;
1023 select has_table_privilege(t1.oid,'trigger')
1024 from (select oid from pg_class where relname = 'pg_authid') as t1;
1027 SET SESSION AUTHORIZATION regress_priv_user3;
1029 select has_table_privilege(current_user,'pg_class','select');
1030 select has_table_privilege(current_user,'pg_class','insert');
1032 select has_table_privilege(t2.oid,'pg_class','update')
1033 from (select oid from pg_roles where rolname = current_user) as t2;
1034 select has_table_privilege(t2.oid,'pg_class','delete')
1035 from (select oid from pg_roles where rolname = current_user) as t2;
1037 select has_table_privilege(current_user,t1.oid,'references')
1038 from (select oid from pg_class where relname = 'pg_class') as t1;
1040 select has_table_privilege(t2.oid,t1.oid,'select')
1041 from (select oid from pg_class where relname = 'pg_class') as t1,
1042 (select oid from pg_roles where rolname = current_user) as t2;
1043 select has_table_privilege(t2.oid,t1.oid,'insert')
1044 from (select oid from pg_class where relname = 'pg_class') as t1,
1045 (select oid from pg_roles where rolname = current_user) as t2;
1047 select has_table_privilege('pg_class','update');
1048 select has_table_privilege('pg_class','delete');
1049 select has_table_privilege('pg_class','truncate');
1051 select has_table_privilege(t1.oid,'select')
1052 from (select oid from pg_class where relname = 'pg_class') as t1;
1053 select has_table_privilege(t1.oid,'trigger')
1054 from (select oid from pg_class where relname = 'pg_class') as t1;
1056 select has_table_privilege(current_user,'atest1','select');
1057 select has_table_privilege(current_user,'atest1','insert');
1059 select has_table_privilege(t2.oid,'atest1','update')
1060 from (select oid from pg_roles where rolname = current_user) as t2;
1061 select has_table_privilege(t2.oid,'atest1','delete')
1062 from (select oid from pg_roles where rolname = current_user) as t2;
1064 select has_table_privilege(current_user,t1.oid,'references')
1065 from (select oid from pg_class where relname = 'atest1') as t1;
1067 select has_table_privilege(t2.oid,t1.oid,'select')
1068 from (select oid from pg_class where relname = 'atest1') as t1,
1069 (select oid from pg_roles where rolname = current_user) as t2;
1070 select has_table_privilege(t2.oid,t1.oid,'insert')
1071 from (select oid from pg_class where relname = 'atest1') as t1,
1072 (select oid from pg_roles where rolname = current_user) as t2;
1074 select has_table_privilege('atest1','update');
1075 select has_table_privilege('atest1','delete');
1076 select has_table_privilege('atest1','truncate');
1078 select has_table_privilege(t1.oid,'select')
1079 from (select oid from pg_class where relname = 'atest1') as t1;
1080 select has_table_privilege(t1.oid,'trigger')
1081 from (select oid from pg_class where relname = 'atest1') as t1;
1083 -- has_column_privilege function
1085 -- bad-input checks (as non-super-user)
1086 select has_column_privilege('pg_authid',NULL,'select');
1087 select has_column_privilege('pg_authid','nosuchcol','select');
1088 select has_column_privilege(9999,'nosuchcol','select');
1089 select has_column_privilege(9999,99::int2,'select');
1090 select has_column_privilege('pg_authid',99::int2,'select');
1091 select has_column_privilege(9999,99::int2,'select');
1093 create temp table mytable(f1 int, f2 int, f3 int);
1094 alter table mytable drop column f2;
1095 select has_column_privilege('mytable','f2','select');
1096 select has_column_privilege('mytable','........pg.dropped.2........','select');
1097 select has_column_privilege('mytable',2::int2,'select');
1098 select has_column_privilege('mytable',99::int2,'select');
1099 revoke select on table mytable from regress_priv_user3;
1100 select has_column_privilege('mytable',2::int2,'select');
1101 select has_column_privilege('mytable',99::int2,'select');
1106 SET SESSION AUTHORIZATION regress_priv_user1;
1108 CREATE TABLE atest4 (a int);
1110 GRANT SELECT ON atest4 TO regress_priv_user2 WITH GRANT OPTION;
1111 GRANT UPDATE ON atest4 TO regress_priv_user2;
1112 GRANT SELECT ON atest4 TO GROUP regress_priv_group1 WITH GRANT OPTION;
1114 SET SESSION AUTHORIZATION regress_priv_user2;
1116 GRANT SELECT ON atest4 TO regress_priv_user3;
1117 GRANT UPDATE ON atest4 TO regress_priv_user3; -- fail
1119 SET SESSION AUTHORIZATION regress_priv_user1;
1121 REVOKE SELECT ON atest4 FROM regress_priv_user3; -- does nothing
1122 SELECT has_table_privilege('regress_priv_user3', 'atest4', 'SELECT'); -- true
1123 REVOKE SELECT ON atest4 FROM regress_priv_user2; -- fail
1124 REVOKE GRANT OPTION FOR SELECT ON atest4 FROM regress_priv_user2 CASCADE; -- ok
1125 SELECT has_table_privilege('regress_priv_user2', 'atest4', 'SELECT'); -- true
1126 SELECT has_table_privilege('regress_priv_user3', 'atest4', 'SELECT'); -- false
1128 SELECT has_table_privilege('regress_priv_user1', 'atest4', 'SELECT WITH GRANT OPTION'); -- true
1131 -- security-restricted operations
1133 CREATE ROLE regress_sro_user;
1135 -- Check that index expressions and predicates are run as the table's owner
1137 -- A dummy index function checking current_user
1138 CREATE FUNCTION sro_ifun(int) RETURNS int AS $$
1140 -- Below we set the table's owner to regress_sro_user
1141 ASSERT current_user = 'regress_sro_user',
1142 format('sro_ifun(%s) called by %s', $1, current_user);
1145 $$ LANGUAGE plpgsql IMMUTABLE;
1146 -- Create a table owned by regress_sro_user
1147 CREATE TABLE sro_tab (a int);
1148 ALTER TABLE sro_tab OWNER TO regress_sro_user;
1149 INSERT INTO sro_tab VALUES (1), (2), (3);
1150 -- Create an expression index with a predicate
1151 CREATE INDEX sro_idx ON sro_tab ((sro_ifun(a) + sro_ifun(0)))
1152 WHERE sro_ifun(a + 10) > sro_ifun(10);
1154 -- Do the same concurrently
1155 CREATE INDEX CONCURRENTLY sro_idx ON sro_tab ((sro_ifun(a) + sro_ifun(0)))
1156 WHERE sro_ifun(a + 10) > sro_ifun(10);
1158 REINDEX TABLE sro_tab;
1159 REINDEX INDEX sro_idx;
1160 REINDEX TABLE CONCURRENTLY sro_tab;
1163 CREATE INDEX sro_cluster_idx ON sro_tab ((sro_ifun(a) + sro_ifun(0)));
1164 CLUSTER sro_tab USING sro_cluster_idx;
1165 DROP INDEX sro_cluster_idx;
1167 CREATE INDEX sro_brin ON sro_tab USING brin ((sro_ifun(a) + sro_ifun(0)));
1168 SELECT brin_desummarize_range('sro_brin', 0);
1169 SELECT brin_summarize_range('sro_brin', 0);
1171 -- Check with a partitioned table
1172 CREATE TABLE sro_ptab (a int) PARTITION BY RANGE (a);
1173 ALTER TABLE sro_ptab OWNER TO regress_sro_user;
1174 CREATE TABLE sro_part PARTITION OF sro_ptab FOR VALUES FROM (1) TO (10);
1175 ALTER TABLE sro_part OWNER TO regress_sro_user;
1176 INSERT INTO sro_ptab VALUES (1), (2), (3);
1177 CREATE INDEX sro_pidx ON sro_ptab ((sro_ifun(a) + sro_ifun(0)))
1178 WHERE sro_ifun(a + 10) > sro_ifun(10);
1179 REINDEX TABLE sro_ptab;
1180 REINDEX INDEX CONCURRENTLY sro_pidx;
1182 SET SESSION AUTHORIZATION regress_sro_user;
1183 CREATE FUNCTION unwanted_grant() RETURNS void LANGUAGE sql AS
1184 'GRANT regress_priv_group2 TO regress_sro_user';
1185 CREATE FUNCTION mv_action() RETURNS bool LANGUAGE sql AS
1186 'DECLARE c CURSOR WITH HOLD FOR SELECT public.unwanted_grant(); SELECT true';
1187 -- REFRESH of this MV will queue a GRANT at end of transaction
1188 CREATE MATERIALIZED VIEW sro_mv AS SELECT mv_action() WITH NO DATA;
1189 REFRESH MATERIALIZED VIEW sro_mv;
1191 REFRESH MATERIALIZED VIEW sro_mv;
1193 SET SESSION AUTHORIZATION regress_sro_user;
1194 -- INSERT to this table will queue a GRANT at end of transaction
1195 CREATE TABLE sro_trojan_table ();
1196 CREATE FUNCTION sro_trojan() RETURNS trigger LANGUAGE plpgsql AS
1197 'BEGIN PERFORM public.unwanted_grant(); RETURN NULL; END';
1198 CREATE CONSTRAINT TRIGGER t AFTER INSERT ON sro_trojan_table
1199 INITIALLY DEFERRED FOR EACH ROW EXECUTE PROCEDURE sro_trojan();
1200 -- Now, REFRESH will issue such an INSERT, queueing the GRANT
1201 CREATE OR REPLACE FUNCTION mv_action() RETURNS bool LANGUAGE sql AS
1202 'INSERT INTO public.sro_trojan_table DEFAULT VALUES; SELECT true';
1203 REFRESH MATERIALIZED VIEW sro_mv;
1205 REFRESH MATERIALIZED VIEW sro_mv;
1206 BEGIN; SET CONSTRAINTS ALL IMMEDIATE; REFRESH MATERIALIZED VIEW sro_mv; COMMIT;
1208 -- REFRESH MATERIALIZED VIEW CONCURRENTLY use of eval_const_expressions()
1209 SET SESSION AUTHORIZATION regress_sro_user;
1210 CREATE FUNCTION unwanted_grant_nofail(int) RETURNS int
1211 IMMUTABLE LANGUAGE plpgsql AS $$
1213 PERFORM public.unwanted_grant();
1214 RAISE WARNING 'owned';
1216 EXCEPTION WHEN OTHERS THEN
1219 CREATE MATERIALIZED VIEW sro_index_mv AS SELECT 1 AS c;
1220 CREATE UNIQUE INDEX ON sro_index_mv (c) WHERE unwanted_grant_nofail(1) > 0;
1222 REFRESH MATERIALIZED VIEW CONCURRENTLY sro_index_mv;
1223 REFRESH MATERIALIZED VIEW sro_index_mv;
1225 DROP OWNED BY regress_sro_user;
1226 DROP ROLE regress_sro_user;
1231 SET SESSION AUTHORIZATION regress_priv_user4;
1232 CREATE FUNCTION dogrant_ok() RETURNS void LANGUAGE sql SECURITY DEFINER AS
1233 'GRANT regress_priv_group2 TO regress_priv_user5';
1234 GRANT regress_priv_group2 TO regress_priv_user5; -- ok: had ADMIN OPTION
1235 SET ROLE regress_priv_group2;
1236 GRANT regress_priv_group2 TO regress_priv_user5; -- fails: SET ROLE suspended privilege
1238 SET SESSION AUTHORIZATION regress_priv_user1;
1239 GRANT regress_priv_group2 TO regress_priv_user5; -- fails: no ADMIN OPTION
1240 SELECT dogrant_ok(); -- ok: SECURITY DEFINER conveys ADMIN
1241 SET ROLE regress_priv_group2;
1242 GRANT regress_priv_group2 TO regress_priv_user5; -- fails: SET ROLE did not help
1244 SET SESSION AUTHORIZATION regress_priv_group2;
1245 GRANT regress_priv_group2 TO regress_priv_user5; -- fails: no self-admin
1247 SET SESSION AUTHORIZATION regress_priv_user4;
1248 DROP FUNCTION dogrant_ok();
1249 REVOKE regress_priv_group2 FROM regress_priv_user5;
1252 -- has_sequence_privilege tests
1255 CREATE SEQUENCE x_seq;
1257 GRANT USAGE on x_seq to regress_priv_user2;
1259 SELECT has_sequence_privilege('regress_priv_user1', 'atest1', 'SELECT');
1260 SELECT has_sequence_privilege('regress_priv_user1', 'x_seq', 'INSERT');
1261 SELECT has_sequence_privilege('regress_priv_user1', 'x_seq', 'SELECT');
1263 SET SESSION AUTHORIZATION regress_priv_user2;
1265 SELECT has_sequence_privilege('x_seq', 'USAGE');
1267 -- largeobject privilege tests
1269 SET SESSION AUTHORIZATION regress_priv_user1;
1271 SELECT lo_create(1001);
1272 SELECT lo_create(1002);
1273 SELECT lo_create(1003);
1274 SELECT lo_create(1004);
1275 SELECT lo_create(1005);
1277 GRANT ALL ON LARGE OBJECT 1001 TO PUBLIC;
1278 GRANT SELECT ON LARGE OBJECT 1003 TO regress_priv_user2;
1279 GRANT SELECT,UPDATE ON LARGE OBJECT 1004 TO regress_priv_user2;
1280 GRANT ALL ON LARGE OBJECT 1005 TO regress_priv_user2;
1281 GRANT SELECT ON LARGE OBJECT 1005 TO regress_priv_user2 WITH GRANT OPTION;
1283 GRANT SELECT, INSERT ON LARGE OBJECT 1001 TO PUBLIC; -- to be failed
1284 GRANT SELECT, UPDATE ON LARGE OBJECT 1001 TO nosuchuser; -- to be failed
1285 GRANT SELECT, UPDATE ON LARGE OBJECT 999 TO PUBLIC; -- to be failed
1288 SET SESSION AUTHORIZATION regress_priv_user2;
1290 SELECT lo_create(2001);
1291 SELECT lo_create(2002);
1293 SELECT loread(lo_open(1001, x'20000'::int), 32); -- allowed, for now
1294 SELECT lowrite(lo_open(1001, x'40000'::int), 'abcd'); -- fail, wrong mode
1296 SELECT loread(lo_open(1001, x'40000'::int), 32);
1297 SELECT loread(lo_open(1002, x'40000'::int), 32); -- to be denied
1298 SELECT loread(lo_open(1003, x'40000'::int), 32);
1299 SELECT loread(lo_open(1004, x'40000'::int), 32);
1301 SELECT lowrite(lo_open(1001, x'20000'::int), 'abcd');
1302 SELECT lowrite(lo_open(1002, x'20000'::int), 'abcd'); -- to be denied
1303 SELECT lowrite(lo_open(1003, x'20000'::int), 'abcd'); -- to be denied
1304 SELECT lowrite(lo_open(1004, x'20000'::int), 'abcd');
1306 GRANT SELECT ON LARGE OBJECT 1005 TO regress_priv_user3;
1307 GRANT UPDATE ON LARGE OBJECT 1006 TO regress_priv_user3; -- to be denied
1308 REVOKE ALL ON LARGE OBJECT 2001, 2002 FROM PUBLIC;
1309 GRANT ALL ON LARGE OBJECT 2001 TO regress_priv_user3;
1311 SELECT lo_unlink(1001); -- to be denied
1312 SELECT lo_unlink(2002);
1315 -- confirm ACL setting
1316 SELECT oid, pg_get_userbyid(lomowner) ownername, lomacl FROM pg_largeobject_metadata WHERE oid >= 1000 AND oid < 3000 ORDER BY oid;
1318 SET SESSION AUTHORIZATION regress_priv_user3;
1320 SELECT loread(lo_open(1001, x'40000'::int), 32);
1321 SELECT loread(lo_open(1003, x'40000'::int), 32); -- to be denied
1322 SELECT loread(lo_open(1005, x'40000'::int), 32);
1324 SELECT lo_truncate(lo_open(1005, x'20000'::int), 10); -- to be denied
1325 SELECT lo_truncate(lo_open(2001, x'20000'::int), 10);
1327 -- has_largeobject_privilege function
1331 SELECT has_largeobject_privilege(1001, 'SELECT');
1332 SELECT has_largeobject_privilege(1002, 'SELECT');
1333 SELECT has_largeobject_privilege(1003, 'SELECT');
1334 SELECT has_largeobject_privilege(1004, 'SELECT');
1336 SELECT has_largeobject_privilege(1001, 'UPDATE');
1337 SELECT has_largeobject_privilege(1002, 'UPDATE');
1338 SELECT has_largeobject_privilege(1003, 'UPDATE');
1339 SELECT has_largeobject_privilege(1004, 'UPDATE');
1341 -- not-existing large object
1342 SELECT has_largeobject_privilege(9999, 'SELECT'); -- NULL
1345 SET SESSION AUTHORIZATION regress_priv_user2;
1346 SELECT has_largeobject_privilege(1001, 'SELECT');
1347 SELECT has_largeobject_privilege(1002, 'SELECT'); -- false
1348 SELECT has_largeobject_privilege(1003, 'SELECT');
1349 SELECT has_largeobject_privilege(1004, 'SELECT');
1351 SELECT has_largeobject_privilege(1001, 'UPDATE');
1352 SELECT has_largeobject_privilege(1002, 'UPDATE'); -- false
1353 SELECT has_largeobject_privilege(1003, 'UPDATE'); -- false
1354 SELECT has_largeobject_privilege(1004, 'UPDATE');
1356 SELECT has_largeobject_privilege('regress_priv_user3', 1001, 'SELECT');
1357 SELECT has_largeobject_privilege('regress_priv_user3', 1003, 'SELECT'); -- false
1358 SELECT has_largeobject_privilege('regress_priv_user3', 1005, 'SELECT');
1360 SELECT has_largeobject_privilege('regress_priv_user3', 1005, 'UPDATE'); -- false
1361 SELECT has_largeobject_privilege('regress_priv_user3', 2001, 'UPDATE');
1363 -- compatibility mode in largeobject permission
1365 SET lo_compat_privileges = false; -- default setting
1366 SET SESSION AUTHORIZATION regress_priv_user4;
1368 SELECT has_largeobject_privilege(1002, 'SELECT'); -- false
1369 SELECT has_largeobject_privilege(1002, 'UPDATE'); -- false
1371 SELECT loread(lo_open(1002, x'40000'::int), 32); -- to be denied
1372 SELECT lowrite(lo_open(1002, x'20000'::int), 'abcd'); -- to be denied
1373 SELECT lo_truncate(lo_open(1002, x'20000'::int), 10); -- to be denied
1374 SELECT lo_put(1002, 1, 'abcd'); -- to be denied
1375 SELECT lo_unlink(1002); -- to be denied
1376 SELECT lo_export(1001, '/dev/null'); -- to be denied
1377 SELECT lo_import('/dev/null'); -- to be denied
1378 SELECT lo_import('/dev/null', 2003); -- to be denied
1381 SET lo_compat_privileges = true; -- compatibility mode
1382 SET SESSION AUTHORIZATION regress_priv_user4;
1384 SELECT has_largeobject_privilege(1002, 'SELECT'); -- true
1385 SELECT has_largeobject_privilege(1002, 'UPDATE'); -- true
1387 SELECT loread(lo_open(1002, x'40000'::int), 32);
1388 SELECT lowrite(lo_open(1002, x'20000'::int), 'abcd');
1389 SELECT lo_truncate(lo_open(1002, x'20000'::int), 10);
1390 SELECT lo_unlink(1002);
1391 SELECT lo_export(1001, '/dev/null'); -- to be denied
1393 -- don't allow unpriv users to access pg_largeobject contents
1395 SELECT * FROM pg_largeobject LIMIT 0;
1397 SET SESSION AUTHORIZATION regress_priv_user1;
1398 SELECT * FROM pg_largeobject LIMIT 0; -- to be denied
1400 -- pg_signal_backend can't signal superusers
1401 RESET SESSION AUTHORIZATION;
1403 CREATE OR REPLACE FUNCTION terminate_nothrow(pid int) RETURNS bool
1404 LANGUAGE plpgsql SECURITY DEFINER SET client_min_messages = error AS $$
1406 RETURN pg_terminate_backend($1);
1407 EXCEPTION WHEN OTHERS THEN
1410 ALTER FUNCTION terminate_nothrow OWNER TO pg_signal_backend;
1411 SELECT backend_type FROM pg_stat_activity
1412 WHERE CASE WHEN COALESCE(usesysid, 10) = 10 THEN terminate_nothrow(pid) END;
1415 -- test pg_database_owner
1416 RESET SESSION AUTHORIZATION;
1417 GRANT pg_database_owner TO regress_priv_user1;
1418 GRANT regress_priv_user1 TO pg_database_owner;
1419 CREATE TABLE datdba_only ();
1420 ALTER TABLE datdba_only OWNER TO pg_database_owner;
1421 REVOKE DELETE ON datdba_only FROM pg_database_owner;
1423 pg_has_role('regress_priv_user1', 'pg_database_owner', 'USAGE') as priv,
1424 pg_has_role('regress_priv_user1', 'pg_database_owner', 'MEMBER') as mem,
1425 pg_has_role('regress_priv_user1', 'pg_database_owner',
1426 'MEMBER WITH ADMIN OPTION') as admin;
1429 DO $$BEGIN EXECUTE format(
1430 'ALTER DATABASE %I OWNER TO regress_priv_group2', current_catalog); END$$;
1432 pg_has_role('regress_priv_user1', 'pg_database_owner', 'USAGE') as priv,
1433 pg_has_role('regress_priv_user1', 'pg_database_owner', 'MEMBER') as mem,
1434 pg_has_role('regress_priv_user1', 'pg_database_owner',
1435 'MEMBER WITH ADMIN OPTION') as admin;
1436 SET SESSION AUTHORIZATION regress_priv_user1;
1437 TABLE information_schema.enabled_roles ORDER BY role_name COLLATE "C";
1438 TABLE information_schema.applicable_roles ORDER BY role_name COLLATE "C";
1439 INSERT INTO datdba_only DEFAULT VALUES;
1440 SAVEPOINT q; DELETE FROM datdba_only; ROLLBACK TO q;
1441 SET SESSION AUTHORIZATION regress_priv_user2;
1442 TABLE information_schema.enabled_roles;
1443 INSERT INTO datdba_only DEFAULT VALUES;
1446 -- test default ACLs
1449 CREATE SCHEMA testns;
1450 GRANT ALL ON SCHEMA testns TO regress_priv_user1;
1452 CREATE TABLE testns.acltest1 (x int);
1453 SELECT has_table_privilege('regress_priv_user1', 'testns.acltest1', 'SELECT'); -- no
1454 SELECT has_table_privilege('regress_priv_user1', 'testns.acltest1', 'INSERT'); -- no
1456 -- placeholder for test with duplicated schema and role names
1457 ALTER DEFAULT PRIVILEGES IN SCHEMA testns,testns GRANT SELECT ON TABLES TO public,public;
1459 SELECT has_table_privilege('regress_priv_user1', 'testns.acltest1', 'SELECT'); -- no
1460 SELECT has_table_privilege('regress_priv_user1', 'testns.acltest1', 'INSERT'); -- no
1462 DROP TABLE testns.acltest1;
1463 CREATE TABLE testns.acltest1 (x int);
1465 SELECT has_table_privilege('regress_priv_user1', 'testns.acltest1', 'SELECT'); -- yes
1466 SELECT has_table_privilege('regress_priv_user1', 'testns.acltest1', 'INSERT'); -- no
1468 ALTER DEFAULT PRIVILEGES IN SCHEMA testns GRANT INSERT ON TABLES TO regress_priv_user1;
1470 DROP TABLE testns.acltest1;
1471 CREATE TABLE testns.acltest1 (x int);
1473 SELECT has_table_privilege('regress_priv_user1', 'testns.acltest1', 'SELECT'); -- yes
1474 SELECT has_table_privilege('regress_priv_user1', 'testns.acltest1', 'INSERT'); -- yes
1476 ALTER DEFAULT PRIVILEGES IN SCHEMA testns REVOKE INSERT ON TABLES FROM regress_priv_user1;
1478 DROP TABLE testns.acltest1;
1479 CREATE TABLE testns.acltest1 (x int);
1481 SELECT has_table_privilege('regress_priv_user1', 'testns.acltest1', 'SELECT'); -- yes
1482 SELECT has_table_privilege('regress_priv_user1', 'testns.acltest1', 'INSERT'); -- no
1484 ALTER DEFAULT PRIVILEGES FOR ROLE regress_priv_user1 REVOKE EXECUTE ON FUNCTIONS FROM public;
1486 ALTER DEFAULT PRIVILEGES IN SCHEMA testns GRANT USAGE ON SCHEMAS TO regress_priv_user2; -- error
1488 -- Test makeaclitem()
1489 SELECT makeaclitem('regress_priv_user1'::regrole, 'regress_priv_user2'::regrole,
1490 'SELECT', TRUE); -- single privilege
1491 SELECT makeaclitem('regress_priv_user1'::regrole, 'regress_priv_user2'::regrole,
1492 'SELECT, INSERT, UPDATE , DELETE ', FALSE); -- multiple privileges
1493 SELECT makeaclitem('regress_priv_user1'::regrole, 'regress_priv_user2'::regrole,
1494 'SELECT, fake_privilege', FALSE); -- error
1496 -- Test non-throwing aclitem I/O
1497 SELECT pg_input_is_valid('regress_priv_user1=r/regress_priv_user2', 'aclitem');
1498 SELECT pg_input_is_valid('regress_priv_user1=r/', 'aclitem');
1499 SELECT * FROM pg_input_error_info('regress_priv_user1=r/', 'aclitem');
1500 SELECT pg_input_is_valid('regress_priv_user1=r/regress_no_such_user', 'aclitem');
1501 SELECT * FROM pg_input_error_info('regress_priv_user1=r/regress_no_such_user', 'aclitem');
1502 SELECT pg_input_is_valid('regress_priv_user1=rY', 'aclitem');
1503 SELECT * FROM pg_input_error_info('regress_priv_user1=rY', 'aclitem');
1506 -- Testing blanket default grants is very hazardous since it might change
1507 -- the privileges attached to objects created by concurrent regression tests.
1508 -- To avoid that, be sure to revoke the privileges again before committing.
1512 ALTER DEFAULT PRIVILEGES GRANT USAGE ON SCHEMAS TO regress_priv_user2;
1514 CREATE SCHEMA testns2;
1516 SELECT has_schema_privilege('regress_priv_user2', 'testns2', 'USAGE'); -- yes
1517 SELECT has_schema_privilege('regress_priv_user6', 'testns2', 'USAGE'); -- yes
1518 SELECT has_schema_privilege('regress_priv_user2', 'testns2', 'CREATE'); -- no
1520 ALTER DEFAULT PRIVILEGES REVOKE USAGE ON SCHEMAS FROM regress_priv_user2;
1522 CREATE SCHEMA testns3;
1524 SELECT has_schema_privilege('regress_priv_user2', 'testns3', 'USAGE'); -- no
1525 SELECT has_schema_privilege('regress_priv_user2', 'testns3', 'CREATE'); -- no
1527 ALTER DEFAULT PRIVILEGES GRANT ALL ON SCHEMAS TO regress_priv_user2;
1529 CREATE SCHEMA testns4;
1531 SELECT has_schema_privilege('regress_priv_user2', 'testns4', 'USAGE'); -- yes
1532 SELECT has_schema_privilege('regress_priv_user2', 'testns4', 'CREATE'); -- yes
1534 ALTER DEFAULT PRIVILEGES REVOKE ALL ON SCHEMAS FROM regress_priv_user2;
1538 -- Test for DROP OWNED BY with shared dependencies. This is done in a
1539 -- separate, rollbacked, transaction to avoid any trouble with other
1540 -- regression sessions.
1542 ALTER DEFAULT PRIVILEGES GRANT ALL ON FUNCTIONS TO regress_priv_user2;
1543 ALTER DEFAULT PRIVILEGES GRANT ALL ON SCHEMAS TO regress_priv_user2;
1544 ALTER DEFAULT PRIVILEGES GRANT ALL ON SEQUENCES TO regress_priv_user2;
1545 ALTER DEFAULT PRIVILEGES GRANT ALL ON TABLES TO regress_priv_user2;
1546 ALTER DEFAULT PRIVILEGES GRANT ALL ON TYPES TO regress_priv_user2;
1547 SELECT count(*) FROM pg_shdepend
1548 WHERE deptype = 'a' AND
1549 refobjid = 'regress_priv_user2'::regrole AND
1550 classid = 'pg_default_acl'::regclass;
1551 DROP OWNED BY regress_priv_user2, regress_priv_user2;
1552 SELECT count(*) FROM pg_shdepend
1553 WHERE deptype = 'a' AND
1554 refobjid = 'regress_priv_user2'::regrole AND
1555 classid = 'pg_default_acl'::regclass;
1558 CREATE SCHEMA testns5;
1560 SELECT has_schema_privilege('regress_priv_user2', 'testns5', 'USAGE'); -- no
1561 SELECT has_schema_privilege('regress_priv_user2', 'testns5', 'CREATE'); -- no
1563 SET ROLE regress_priv_user1;
1565 CREATE FUNCTION testns.foo() RETURNS int AS 'select 1' LANGUAGE sql;
1566 CREATE AGGREGATE testns.agg1(int) (sfunc = int4pl, stype = int4);
1567 CREATE PROCEDURE testns.bar() AS 'select 1' LANGUAGE sql;
1569 SELECT has_function_privilege('regress_priv_user2', 'testns.foo()', 'EXECUTE'); -- no
1570 SELECT has_function_privilege('regress_priv_user2', 'testns.agg1(int)', 'EXECUTE'); -- no
1571 SELECT has_function_privilege('regress_priv_user2', 'testns.bar()', 'EXECUTE'); -- no
1573 ALTER DEFAULT PRIVILEGES IN SCHEMA testns GRANT EXECUTE ON ROUTINES to public;
1575 DROP FUNCTION testns.foo();
1576 CREATE FUNCTION testns.foo() RETURNS int AS 'select 1' LANGUAGE sql;
1577 DROP AGGREGATE testns.agg1(int);
1578 CREATE AGGREGATE testns.agg1(int) (sfunc = int4pl, stype = int4);
1579 DROP PROCEDURE testns.bar();
1580 CREATE PROCEDURE testns.bar() AS 'select 1' LANGUAGE sql;
1582 SELECT has_function_privilege('regress_priv_user2', 'testns.foo()', 'EXECUTE'); -- yes
1583 SELECT has_function_privilege('regress_priv_user2', 'testns.agg1(int)', 'EXECUTE'); -- yes
1584 SELECT has_function_privilege('regress_priv_user2', 'testns.bar()', 'EXECUTE'); -- yes (counts as function here)
1586 DROP FUNCTION testns.foo();
1587 DROP AGGREGATE testns.agg1(int);
1588 DROP PROCEDURE testns.bar();
1590 ALTER DEFAULT PRIVILEGES FOR ROLE regress_priv_user1 REVOKE USAGE ON TYPES FROM public;
1592 CREATE DOMAIN testns.priv_testdomain1 AS int;
1594 SELECT has_type_privilege('regress_priv_user2', 'testns.priv_testdomain1', 'USAGE'); -- no
1596 ALTER DEFAULT PRIVILEGES IN SCHEMA testns GRANT USAGE ON TYPES to public;
1598 DROP DOMAIN testns.priv_testdomain1;
1599 CREATE DOMAIN testns.priv_testdomain1 AS int;
1601 SELECT has_type_privilege('regress_priv_user2', 'testns.priv_testdomain1', 'USAGE'); -- yes
1603 DROP DOMAIN testns.priv_testdomain1;
1608 FROM pg_default_acl d LEFT JOIN pg_namespace n ON defaclnamespace = n.oid
1609 WHERE nspname = 'testns';
1611 DROP SCHEMA testns CASCADE;
1612 DROP SCHEMA testns2 CASCADE;
1613 DROP SCHEMA testns3 CASCADE;
1614 DROP SCHEMA testns4 CASCADE;
1615 DROP SCHEMA testns5 CASCADE;
1617 SELECT d.* -- check that entries went away
1618 FROM pg_default_acl d LEFT JOIN pg_namespace n ON defaclnamespace = n.oid
1619 WHERE nspname IS NULL AND defaclnamespace != 0;
1622 -- Grant on all objects of given type in a schema
1625 CREATE SCHEMA testns;
1626 CREATE TABLE testns.t1 (f1 int);
1627 CREATE TABLE testns.t2 (f1 int);
1629 SELECT has_table_privilege('regress_priv_user1', 'testns.t1', 'SELECT'); -- false
1631 GRANT ALL ON ALL TABLES IN SCHEMA testns TO regress_priv_user1;
1633 SELECT has_table_privilege('regress_priv_user1', 'testns.t1', 'SELECT'); -- true
1634 SELECT has_table_privilege('regress_priv_user1', 'testns.t2', 'SELECT'); -- true
1636 REVOKE ALL ON ALL TABLES IN SCHEMA testns FROM regress_priv_user1;
1638 SELECT has_table_privilege('regress_priv_user1', 'testns.t1', 'SELECT'); -- false
1639 SELECT has_table_privilege('regress_priv_user1', 'testns.t2', 'SELECT'); -- false
1641 CREATE FUNCTION testns.priv_testfunc(int) RETURNS int AS 'select 3 * $1;' LANGUAGE sql;
1642 CREATE AGGREGATE testns.priv_testagg(int) (sfunc = int4pl, stype = int4);
1643 CREATE PROCEDURE testns.priv_testproc(int) AS 'select 3' LANGUAGE sql;
1645 SELECT has_function_privilege('regress_priv_user1', 'testns.priv_testfunc(int)', 'EXECUTE'); -- true by default
1646 SELECT has_function_privilege('regress_priv_user1', 'testns.priv_testagg(int)', 'EXECUTE'); -- true by default
1647 SELECT has_function_privilege('regress_priv_user1', 'testns.priv_testproc(int)', 'EXECUTE'); -- true by default
1649 REVOKE ALL ON ALL FUNCTIONS IN SCHEMA testns FROM PUBLIC;
1651 SELECT has_function_privilege('regress_priv_user1', 'testns.priv_testfunc(int)', 'EXECUTE'); -- false
1652 SELECT has_function_privilege('regress_priv_user1', 'testns.priv_testagg(int)', 'EXECUTE'); -- false
1653 SELECT has_function_privilege('regress_priv_user1', 'testns.priv_testproc(int)', 'EXECUTE'); -- still true, not a function
1655 REVOKE ALL ON ALL PROCEDURES IN SCHEMA testns FROM PUBLIC;
1657 SELECT has_function_privilege('regress_priv_user1', 'testns.priv_testproc(int)', 'EXECUTE'); -- now false
1659 GRANT ALL ON ALL ROUTINES IN SCHEMA testns TO PUBLIC;
1661 SELECT has_function_privilege('regress_priv_user1', 'testns.priv_testfunc(int)', 'EXECUTE'); -- true
1662 SELECT has_function_privilege('regress_priv_user1', 'testns.priv_testagg(int)', 'EXECUTE'); -- true
1663 SELECT has_function_privilege('regress_priv_user1', 'testns.priv_testproc(int)', 'EXECUTE'); -- true
1665 DROP SCHEMA testns CASCADE;
1668 -- Change owner of the schema & and rename of new schema owner
1671 CREATE ROLE regress_schemauser1 superuser login;
1672 CREATE ROLE regress_schemauser2 superuser login;
1674 SET SESSION ROLE regress_schemauser1;
1675 CREATE SCHEMA testns;
1677 SELECT nspname, rolname FROM pg_namespace, pg_roles WHERE pg_namespace.nspname = 'testns' AND pg_namespace.nspowner = pg_roles.oid;
1679 ALTER SCHEMA testns OWNER TO regress_schemauser2;
1680 ALTER ROLE regress_schemauser2 RENAME TO regress_schemauser_renamed;
1681 SELECT nspname, rolname FROM pg_namespace, pg_roles WHERE pg_namespace.nspname = 'testns' AND pg_namespace.nspowner = pg_roles.oid;
1683 set session role regress_schemauser_renamed;
1684 DROP SCHEMA testns CASCADE;
1689 DROP ROLE regress_schemauser1;
1690 DROP ROLE regress_schemauser_renamed;
1693 -- test that dependent privileges are revoked (or not) properly
1696 set session role regress_priv_user1;
1697 create table dep_priv_test (a int);
1698 grant select on dep_priv_test to regress_priv_user2 with grant option;
1699 grant select on dep_priv_test to regress_priv_user3 with grant option;
1700 set session role regress_priv_user2;
1701 grant select on dep_priv_test to regress_priv_user4 with grant option;
1702 set session role regress_priv_user3;
1703 grant select on dep_priv_test to regress_priv_user4 with grant option;
1704 set session role regress_priv_user4;
1705 grant select on dep_priv_test to regress_priv_user5;
1707 set session role regress_priv_user2;
1708 revoke select on dep_priv_test from regress_priv_user4 cascade;
1710 set session role regress_priv_user3;
1711 revoke select on dep_priv_test from regress_priv_user4 cascade;
1713 set session role regress_priv_user1;
1714 drop table dep_priv_test;
1721 drop sequence x_seq;
1723 DROP AGGREGATE priv_testagg1(int);
1724 DROP FUNCTION priv_testfunc2(int);
1725 DROP FUNCTION priv_testfunc4(boolean);
1726 DROP PROCEDURE priv_testproc1(int);
1731 -- this should cascade to drop atestv4
1732 DROP VIEW atestv3 CASCADE;
1733 -- this should complain "does not exist"
1746 SELECT lo_unlink(oid) FROM pg_largeobject_metadata WHERE oid >= 1000 AND oid < 3000 ORDER BY oid;
1748 DROP GROUP regress_priv_group1;
1749 DROP GROUP regress_priv_group2;
1751 -- these are needed to clean up permissions
1752 REVOKE USAGE ON LANGUAGE sql FROM regress_priv_user1;
1753 DROP OWNED BY regress_priv_user1;
1755 DROP USER regress_priv_user1;
1756 DROP USER regress_priv_user2;
1757 DROP USER regress_priv_user3;
1758 DROP USER regress_priv_user4;
1759 DROP USER regress_priv_user5;
1760 DROP USER regress_priv_user6;
1761 DROP USER regress_priv_user7;
1762 DROP USER regress_priv_user8; -- does not exist
1765 -- permissions with LOCK TABLE
1766 CREATE USER regress_locktable_user;
1767 CREATE TABLE lock_table (a int);
1769 -- LOCK TABLE and SELECT permission
1770 GRANT SELECT ON lock_table TO regress_locktable_user;
1771 SET SESSION AUTHORIZATION regress_locktable_user;
1773 LOCK TABLE lock_table IN ACCESS SHARE MODE; -- should pass
1776 LOCK TABLE lock_table IN ROW EXCLUSIVE MODE; -- should fail
1779 LOCK TABLE lock_table IN ACCESS EXCLUSIVE MODE; -- should fail
1782 REVOKE SELECT ON lock_table FROM regress_locktable_user;
1784 -- LOCK TABLE and INSERT permission
1785 GRANT INSERT ON lock_table TO regress_locktable_user;
1786 SET SESSION AUTHORIZATION regress_locktable_user;
1788 LOCK TABLE lock_table IN ACCESS SHARE MODE; -- should pass
1791 LOCK TABLE lock_table IN ROW EXCLUSIVE MODE; -- should pass
1794 LOCK TABLE lock_table IN ACCESS EXCLUSIVE MODE; -- should fail
1797 REVOKE INSERT ON lock_table FROM regress_locktable_user;
1799 -- LOCK TABLE and UPDATE permission
1800 GRANT UPDATE ON lock_table TO regress_locktable_user;
1801 SET SESSION AUTHORIZATION regress_locktable_user;
1803 LOCK TABLE lock_table IN ACCESS SHARE MODE; -- should pass
1806 LOCK TABLE lock_table IN ROW EXCLUSIVE MODE; -- should pass
1809 LOCK TABLE lock_table IN ACCESS EXCLUSIVE MODE; -- should pass
1812 REVOKE UPDATE ON lock_table FROM regress_locktable_user;
1814 -- LOCK TABLE and DELETE permission
1815 GRANT DELETE ON lock_table TO regress_locktable_user;
1816 SET SESSION AUTHORIZATION regress_locktable_user;
1818 LOCK TABLE lock_table IN ACCESS SHARE MODE; -- should pass
1821 LOCK TABLE lock_table IN ROW EXCLUSIVE MODE; -- should pass
1824 LOCK TABLE lock_table IN ACCESS EXCLUSIVE MODE; -- should pass
1827 REVOKE DELETE ON lock_table FROM regress_locktable_user;
1829 -- LOCK TABLE and TRUNCATE permission
1830 GRANT TRUNCATE ON lock_table TO regress_locktable_user;
1831 SET SESSION AUTHORIZATION regress_locktable_user;
1833 LOCK TABLE lock_table IN ACCESS SHARE MODE; -- should pass
1836 LOCK TABLE lock_table IN ROW EXCLUSIVE MODE; -- should pass
1839 LOCK TABLE lock_table IN ACCESS EXCLUSIVE MODE; -- should pass
1842 REVOKE TRUNCATE ON lock_table FROM regress_locktable_user;
1844 -- LOCK TABLE and MAINTAIN permission
1845 GRANT MAINTAIN ON lock_table TO regress_locktable_user;
1846 SET SESSION AUTHORIZATION regress_locktable_user;
1848 LOCK TABLE lock_table IN ACCESS SHARE MODE; -- should pass
1851 LOCK TABLE lock_table IN ROW EXCLUSIVE MODE; -- should pass
1854 LOCK TABLE lock_table IN ACCESS EXCLUSIVE MODE; -- should pass
1857 REVOKE MAINTAIN ON lock_table FROM regress_locktable_user;
1860 DROP TABLE lock_table;
1861 DROP USER regress_locktable_user;
1863 -- test to check privileges of system views pg_shmem_allocations and
1864 -- pg_backend_memory_contexts.
1866 -- switch to superuser
1869 CREATE ROLE regress_readallstats;
1871 SELECT has_table_privilege('regress_readallstats','pg_backend_memory_contexts','SELECT'); -- no
1872 SELECT has_table_privilege('regress_readallstats','pg_shmem_allocations','SELECT'); -- no
1874 GRANT pg_read_all_stats TO regress_readallstats;
1876 SELECT has_table_privilege('regress_readallstats','pg_backend_memory_contexts','SELECT'); -- yes
1877 SELECT has_table_privilege('regress_readallstats','pg_shmem_allocations','SELECT'); -- yes
1879 -- run query to ensure that functions within views can be executed
1880 SET ROLE regress_readallstats;
1881 SELECT COUNT(*) >= 0 AS ok FROM pg_backend_memory_contexts;
1882 SELECT COUNT(*) >= 0 AS ok FROM pg_shmem_allocations;
1886 DROP ROLE regress_readallstats;
1888 -- test role grantor machinery
1889 CREATE ROLE regress_group;
1890 CREATE ROLE regress_group_direct_manager;
1891 CREATE ROLE regress_group_indirect_manager;
1892 CREATE ROLE regress_group_member;
1894 GRANT regress_group TO regress_group_direct_manager WITH INHERIT FALSE, ADMIN TRUE;
1895 GRANT regress_group_direct_manager TO regress_group_indirect_manager;
1897 SET SESSION AUTHORIZATION regress_group_direct_manager;
1898 GRANT regress_group TO regress_group_member;
1899 SELECT member::regrole::text, CASE WHEN grantor = 10 THEN 'BOOTSTRAP SUPERUSER' ELSE grantor::regrole::text END FROM pg_auth_members WHERE roleid = 'regress_group'::regrole ORDER BY 1, 2;
1900 REVOKE regress_group FROM regress_group_member;
1902 SET SESSION AUTHORIZATION regress_group_indirect_manager;
1903 GRANT regress_group TO regress_group_member;
1904 SELECT member::regrole::text, CASE WHEN grantor = 10 THEN 'BOOTSTRAP SUPERUSER' ELSE grantor::regrole::text END FROM pg_auth_members WHERE roleid = 'regress_group'::regrole ORDER BY 1, 2;
1905 REVOKE regress_group FROM regress_group_member;
1907 RESET SESSION AUTHORIZATION;
1908 DROP ROLE regress_group;
1909 DROP ROLE regress_group_direct_manager;
1910 DROP ROLE regress_group_indirect_manager;
1911 DROP ROLE regress_group_member;
1913 -- test SET and INHERIT options with object ownership changes
1914 CREATE ROLE regress_roleoption_protagonist;
1915 CREATE ROLE regress_roleoption_donor;
1916 CREATE ROLE regress_roleoption_recipient;
1917 CREATE SCHEMA regress_roleoption;
1918 GRANT CREATE, USAGE ON SCHEMA regress_roleoption TO PUBLIC;
1919 GRANT regress_roleoption_donor TO regress_roleoption_protagonist WITH INHERIT TRUE, SET FALSE;
1920 GRANT regress_roleoption_recipient TO regress_roleoption_protagonist WITH INHERIT FALSE, SET TRUE;
1921 SET SESSION AUTHORIZATION regress_roleoption_protagonist;
1922 CREATE TABLE regress_roleoption.t1 (a int);
1923 CREATE TABLE regress_roleoption.t2 (a int);
1924 SET SESSION AUTHORIZATION regress_roleoption_donor;
1925 CREATE TABLE regress_roleoption.t3 (a int);
1926 SET SESSION AUTHORIZATION regress_roleoption_recipient;
1927 CREATE TABLE regress_roleoption.t4 (a int);
1928 SET SESSION AUTHORIZATION regress_roleoption_protagonist;
1929 ALTER TABLE regress_roleoption.t1 OWNER TO regress_roleoption_donor; -- fails, can't be come donor
1930 ALTER TABLE regress_roleoption.t2 OWNER TO regress_roleoption_recipient; -- works
1931 ALTER TABLE regress_roleoption.t3 OWNER TO regress_roleoption_protagonist; -- works
1932 ALTER TABLE regress_roleoption.t4 OWNER TO regress_roleoption_protagonist; -- fails, we don't inherit from recipient
1933 RESET SESSION AUTHORIZATION;
1934 DROP TABLE regress_roleoption.t1;
1935 DROP TABLE regress_roleoption.t2;
1936 DROP TABLE regress_roleoption.t3;
1937 DROP TABLE regress_roleoption.t4;
1938 DROP SCHEMA regress_roleoption;
1939 DROP ROLE regress_roleoption_protagonist;
1940 DROP ROLE regress_roleoption_donor;
1941 DROP ROLE regress_roleoption_recipient;
1944 CREATE ROLE regress_no_maintain;
1945 CREATE ROLE regress_maintain;
1946 CREATE ROLE regress_maintain_all IN ROLE pg_maintain;
1947 CREATE TABLE maintain_test (a INT);
1948 CREATE INDEX ON maintain_test (a);
1949 GRANT MAINTAIN ON maintain_test TO regress_maintain;
1950 CREATE MATERIALIZED VIEW refresh_test AS SELECT 1;
1951 GRANT MAINTAIN ON refresh_test TO regress_maintain;
1952 CREATE SCHEMA reindex_test;
1954 -- negative tests; should fail
1955 SET ROLE regress_no_maintain;
1956 VACUUM maintain_test;
1957 ANALYZE maintain_test;
1958 VACUUM (ANALYZE) maintain_test;
1959 CLUSTER maintain_test USING maintain_test_a_idx;
1960 REFRESH MATERIALIZED VIEW refresh_test;
1961 REINDEX TABLE maintain_test;
1962 REINDEX INDEX maintain_test_a_idx;
1963 REINDEX SCHEMA reindex_test;
1966 SET ROLE regress_maintain;
1967 VACUUM maintain_test;
1968 ANALYZE maintain_test;
1969 VACUUM (ANALYZE) maintain_test;
1970 CLUSTER maintain_test USING maintain_test_a_idx;
1971 REFRESH MATERIALIZED VIEW refresh_test;
1972 REINDEX TABLE maintain_test;
1973 REINDEX INDEX maintain_test_a_idx;
1974 REINDEX SCHEMA reindex_test;
1977 SET ROLE regress_maintain_all;
1978 VACUUM maintain_test;
1979 ANALYZE maintain_test;
1980 VACUUM (ANALYZE) maintain_test;
1981 CLUSTER maintain_test USING maintain_test_a_idx;
1982 REFRESH MATERIALIZED VIEW refresh_test;
1983 REINDEX TABLE maintain_test;
1984 REINDEX INDEX maintain_test_a_idx;
1985 REINDEX SCHEMA reindex_test;
1988 DROP TABLE maintain_test;
1989 DROP MATERIALIZED VIEW refresh_test;
1990 DROP SCHEMA reindex_test;
1991 DROP ROLE regress_no_maintain;
1992 DROP ROLE regress_maintain;
1993 DROP ROLE regress_maintain_all;