Skip to content

Commit 159cd84

Browse files
committed
Add regression tests and fix bugs
1 parent b0fd7e9 commit 159cd84

File tree

5 files changed

+408
-29
lines changed

5 files changed

+408
-29
lines changed

.gitignore

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1 @@
1+
results

Makefile

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -1,6 +1,7 @@
11
EXTENSION = pg_permissions
22
DATA = pg_permissions--1.0.sql
33
DOCS = README.pg_permissions
4+
REGRESS = sample
45

56
PG_CONFIG = pg_config
67
PGXS := $(shell $(PG_CONFIG) --pgxs)

expected/sample.out

Lines changed: 218 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,218 @@
1+
CREATE EXTENSION pg_permissions;
2+
/* test roles (will be removed afterwards) */
3+
CREATE ROLE users;
4+
CREATE ROLE user1 LOGIN IN ROLE users;
5+
CREATE ROLE user2 LOGIN IN ROLE users;
6+
/* database */
7+
-- desired permissions
8+
INSERT INTO permission_target
9+
(id, role_name, permissions, object_type, schema_name, object_name, column_name)
10+
VALUES (1, 'users', ARRAY['CONNECT','TEMPORARY']::perm_type[], 'DATABASE', NULL, NULL, NULL),
11+
(2, 'user1', ARRAY['CONNECT','TEMPORARY']::perm_type[], 'DATABASE', NULL, NULL, NULL),
12+
(3, 'user2', ARRAY['CONNECT','TEMPORARY']::perm_type[], 'DATABASE', NULL, NULL, NULL);
13+
-- this should fail
14+
INSERT INTO permission_target
15+
(id, role_name, permissions, object_type, schema_name, object_name, column_name)
16+
VALUES (4, 'user2', ARRAY['CREATE']::perm_type[], 'DATABASE', 'public', NULL, NULL);
17+
ERROR: new row for relation "permission_target" violates check constraint "permission_target_valid"
18+
DETAIL: Failing row contains (4, user2, {CREATE}, DATABASE, public, null, null).
19+
-- actual permissions
20+
REVOKE ALL ON DATABASE contrib_regression FROM PUBLIC;
21+
GRANT CONNECT, TEMPORARY ON DATABASE contrib_regression TO users;
22+
GRANT CREATE ON DATABASE contrib_regression TO user2; -- too much
23+
/* schema */
24+
-- desired permissions
25+
INSERT INTO permission_target
26+
(id, role_name, permissions, object_type, schema_name, object_name, column_name)
27+
VALUES (5, 'users', ARRAY['USAGE']::perm_type[], 'SCHEMA', 'appschema', NULL, NULL),
28+
(6, 'user1', ARRAY['USAGE','CREATE']::perm_type[], 'SCHEMA', 'appschema', NULL, NULL),
29+
(7, 'user2', ARRAY['USAGE']::perm_type[], 'SCHEMA', 'appschema', NULL, NULL);
30+
-- this should fail
31+
INSERT INTO permission_target
32+
(id, role_name, permissions, object_type, schema_name, object_name, column_name)
33+
VALUES (8, 'user2', ARRAY['CREATE']::perm_type[], 'SCHEMA', 'appschema', 'sometable', NULL);
34+
ERROR: new row for relation "permission_target" violates check constraint "permission_target_valid"
35+
DETAIL: Failing row contains (8, user2, {CREATE}, SCHEMA, appschema, sometable, null).
36+
-- actual permissions
37+
CREATE SCHEMA appschema;
38+
GRANT USAGE ON SCHEMA appschema TO PUBLIC; -- missing CREATE for user1
39+
GRANT CREATE ON SCHEMA appschema TO user2; -- too much
40+
/* table */
41+
-- desired permissions
42+
INSERT INTO permission_target
43+
(id, role_name, permissions, object_type, schema_name, object_name, column_name)
44+
VALUES (9, 'user1', ARRAY['SELECT','INSERT','UPDATE','DELETE']::perm_type[], 'TABLE', 'appschema', NULL, NULL),
45+
(10, 'user2', ARRAY['SELECT']::perm_type[], 'TABLE', 'appschema', NULL, NULL);
46+
-- this should fail
47+
INSERT INTO permission_target
48+
(id, role_name, permissions, object_type, schema_name, object_name, column_name)
49+
VALUES (11, 'user2', ARRAY['INSERT']::perm_type[], 'TABLE', 'appschema', 'apptable', 'acolumn');
50+
ERROR: new row for relation "permission_target" violates check constraint "permission_target_valid"
51+
DETAIL: Failing row contains (11, user2, {INSERT}, TABLE, appschema, apptable, acolumn).
52+
-- actual permissions
53+
CREATE TABLE appschema.apptable (
54+
id integer PRIMARY KEY,
55+
val text NOT NULL,
56+
created timestamp with time zone NOT NULL DEFAULT current_timestamp
57+
);
58+
CREATE TABLE appschema.apptable2 (
59+
id integer PRIMARY KEY,
60+
val text NOT NULL,
61+
created timestamp with time zone NOT NULL DEFAULT current_timestamp
62+
); -- missing all permissions on this one
63+
GRANT SELECT, INSERT, UPDATE ON appschema.apptable TO user1; -- missing DELETE
64+
GRANT SELECT, INSERT ON appschema.apptable TO user2; -- extra privilege INSERT
65+
/* column */
66+
-- desired permissions
67+
INSERT INTO permission_target
68+
(id, role_name, permissions, object_type, schema_name, object_name, column_name)
69+
VALUES (12, 'user1', ARRAY['SELECT','INSERT','UPDATE','REFERENCES']::perm_type[], 'COLUMN', 'appschema', 'apptable2', 'val');
70+
-- this should fail
71+
INSERT INTO permission_target
72+
(id, role_name, permissions, object_type, schema_name, object_name, column_name)
73+
VALUES (13, 'user2', ARRAY['DELETE']::perm_type[], 'COLUMN', 'appschema', 'apptable2', 'val');
74+
ERROR: new row for relation "permission_target" violates check constraint "permission_target_valid"
75+
DETAIL: Failing row contains (13, user2, {DELETE}, COLUMN, appschema, apptable2, val).
76+
-- actual permissions
77+
GRANT REFERENCES (val) ON appschema.apptable2 TO user1; -- missing SELECT, INSERT, UPDATE
78+
GRANT UPDATE (val) ON appschema.apptable2 TO user2; -- extra privilege UPDATE
79+
/* view */
80+
-- desired permissions
81+
INSERT INTO permission_target
82+
(id, role_name, permissions, object_type, schema_name, object_name, column_name)
83+
VALUES (14, 'user1', ARRAY['SELECT','INSERT','UPDATE','DELETE']::perm_type[], 'VIEW', 'appschema', 'appview', NULL),
84+
(15, 'user2', ARRAY['SELECT']::perm_type[], 'VIEW', 'appschema', 'appview', NULL);
85+
-- actual permissions
86+
CREATE VIEW appschema.appview AS
87+
SELECT id, val FROM appschema.apptable;
88+
GRANT SELECT ON appschema.appview TO users; -- extra permission to "users"
89+
GRANT INSERT, DELETE ON appschema.appview TO user1; -- missing UPDATE
90+
/* sequence */
91+
-- desired permissions
92+
INSERT INTO permission_target
93+
(id, role_name, permissions, object_type, schema_name, object_name, column_name)
94+
VALUES (16, 'users', ARRAY['USAGE']::perm_type[], 'SEQUENCE', 'appschema', 'appseq', NULL),
95+
(17, 'user1', ARRAY['USAGE','SELECT']::perm_type[], 'SEQUENCE', 'appschema', 'appseq', NULL),
96+
(18, 'user2', ARRAY['USAGE']::perm_type[], 'SEQUENCE', 'appschema', 'appseq', NULL);
97+
-- actual permissions
98+
CREATE SEQUENCE appschema.appseq;
99+
GRANT USAGE ON SEQUENCE appschema.appseq TO users; -- missing SELECT for user1
100+
GRANT UPDATE ON SEQUENCE appschema.appseq TO user2; -- extra permission UPDATE
101+
/* function */
102+
-- desired permissions
103+
INSERT INTO permission_target
104+
(id, role_name, permissions, object_type, schema_name, object_name, column_name)
105+
VALUES (19, 'user1', ARRAY['EXECUTE']::perm_type[], 'FUNCTION', 'appschema', 'appfun(integer)', NULL),
106+
(20, 'user2', ARRAY['EXECUTE']::perm_type[], 'FUNCTION', 'appschema', 'appfun(integer)', NULL);
107+
-- this should fail
108+
INSERT INTO permission_target
109+
(id, role_name, permissions, object_type, schema_name, object_name, column_name)
110+
VALUES (21, 'users', ARRAY['UPDATE']::perm_type[], 'FUNCTION', 'appschema', 'appfun(integer)', NULL);
111+
ERROR: new row for relation "permission_target" violates check constraint "permission_target_valid"
112+
DETAIL: Failing row contains (21, users, {UPDATE}, FUNCTION, appschema, appfun(integer), null).
113+
-- actual permissions
114+
CREATE FUNCTION appschema.appfun(i integer) RETURNS integer
115+
LANGUAGE sql IMMUTABLE AS
116+
'SELECT i + 2'; -- extra permission for "users"
117+
/* report all permissions */
118+
SELECT object_type, role_name, schema_name, object_name, column_name, permission
119+
FROM all_permissions
120+
WHERE granted
121+
AND role_name IN ('users', 'user1', 'user2')
122+
AND coalesce(schema_name, 'appschema') = 'appschema'
123+
ORDER BY object_type, role_name, schema_name, object_name, column_name, permission;
124+
object_type | role_name | schema_name | object_name | column_name | permission
125+
-------------+-----------+-------------+-----------------+-------------+------------
126+
TABLE | user1 | appschema | apptable | | SELECT
127+
TABLE | user1 | appschema | apptable | | INSERT
128+
TABLE | user1 | appschema | apptable | | UPDATE
129+
TABLE | user2 | appschema | apptable | | SELECT
130+
TABLE | user2 | appschema | apptable | | INSERT
131+
VIEW | user1 | appschema | appview | | SELECT
132+
VIEW | user1 | appschema | appview | | INSERT
133+
VIEW | user1 | appschema | appview | | DELETE
134+
VIEW | user2 | appschema | appview | | SELECT
135+
VIEW | users | appschema | appview | | SELECT
136+
COLUMN | user1 | appschema | apptable | created | SELECT
137+
COLUMN | user1 | appschema | apptable | created | INSERT
138+
COLUMN | user1 | appschema | apptable | created | UPDATE
139+
COLUMN | user1 | appschema | apptable | id | SELECT
140+
COLUMN | user1 | appschema | apptable | id | INSERT
141+
COLUMN | user1 | appschema | apptable | id | UPDATE
142+
COLUMN | user1 | appschema | apptable | val | SELECT
143+
COLUMN | user1 | appschema | apptable | val | INSERT
144+
COLUMN | user1 | appschema | apptable | val | UPDATE
145+
COLUMN | user1 | appschema | apptable2 | val | REFERENCES
146+
COLUMN | user1 | appschema | appview | id | SELECT
147+
COLUMN | user1 | appschema | appview | id | INSERT
148+
COLUMN | user1 | appschema | appview | val | SELECT
149+
COLUMN | user1 | appschema | appview | val | INSERT
150+
COLUMN | user2 | appschema | apptable | created | SELECT
151+
COLUMN | user2 | appschema | apptable | created | INSERT
152+
COLUMN | user2 | appschema | apptable | id | SELECT
153+
COLUMN | user2 | appschema | apptable | id | INSERT
154+
COLUMN | user2 | appschema | apptable | val | SELECT
155+
COLUMN | user2 | appschema | apptable | val | INSERT
156+
COLUMN | user2 | appschema | apptable2 | val | UPDATE
157+
COLUMN | user2 | appschema | appview | id | SELECT
158+
COLUMN | user2 | appschema | appview | val | SELECT
159+
COLUMN | users | appschema | appview | id | SELECT
160+
COLUMN | users | appschema | appview | val | SELECT
161+
SEQUENCE | user1 | appschema | appseq | | USAGE
162+
SEQUENCE | user2 | appschema | appseq | | UPDATE
163+
SEQUENCE | user2 | appschema | appseq | | USAGE
164+
SEQUENCE | users | appschema | appseq | | USAGE
165+
FUNCTION | user1 | appschema | appfun(integer) | | EXECUTE
166+
FUNCTION | user2 | appschema | appfun(integer) | | EXECUTE
167+
FUNCTION | users | appschema | appfun(integer) | | EXECUTE
168+
SCHEMA | user1 | appschema | | | USAGE
169+
SCHEMA | user2 | appschema | | | USAGE
170+
SCHEMA | user2 | appschema | | | CREATE
171+
SCHEMA | users | appschema | | | USAGE
172+
DATABASE | user1 | | | | CONNECT
173+
DATABASE | user1 | | | | TEMPORARY
174+
DATABASE | user2 | | | | CREATE
175+
DATABASE | user2 | | | | CONNECT
176+
DATABASE | user2 | | | | TEMPORARY
177+
DATABASE | users | | | | CONNECT
178+
DATABASE | users | | | | TEMPORARY
179+
(53 rows)
180+
181+
/* report differences */
182+
SELECT * FROM permission_diffs()
183+
WHERE role_name IN ('users', 'user1', 'user2')
184+
ORDER BY object_type, schema_name, object_name, column_name, role_name, permission, missing;
185+
missing | role_name | object_type | schema_name | object_name | column_name | permission
186+
---------+-----------+-------------+-------------+-----------------+-------------+------------
187+
t | user1 | TABLE | appschema | apptable | | DELETE
188+
f | user2 | TABLE | appschema | apptable | | INSERT
189+
t | user1 | TABLE | appschema | apptable2 | | SELECT
190+
t | user1 | TABLE | appschema | apptable2 | | INSERT
191+
t | user1 | TABLE | appschema | apptable2 | | UPDATE
192+
t | user1 | TABLE | appschema | apptable2 | | DELETE
193+
t | user2 | TABLE | appschema | apptable2 | | SELECT
194+
t | user1 | VIEW | appschema | appview | | UPDATE
195+
f | users | VIEW | appschema | appview | | SELECT
196+
t | user1 | COLUMN | appschema | apptable2 | val | SELECT
197+
t | user1 | COLUMN | appschema | apptable2 | val | INSERT
198+
t | user1 | COLUMN | appschema | apptable2 | val | UPDATE
199+
f | user2 | COLUMN | appschema | apptable2 | val | UPDATE
200+
t | user1 | SEQUENCE | appschema | appseq | | SELECT
201+
f | user2 | SEQUENCE | appschema | appseq | | UPDATE
202+
f | users | FUNCTION | appschema | appfun(integer) | | EXECUTE
203+
t | user1 | SCHEMA | appschema | | | CREATE
204+
f | user2 | SCHEMA | appschema | | | CREATE
205+
f | user2 | DATABASE | | | | CREATE
206+
(19 rows)
207+
208+
/* clean up */
209+
DROP FUNCTION appschema.appfun(integer);
210+
DROP VIEW appschema.appview;
211+
DROP SEQUENCE appschema.appseq;
212+
DROP TABLE appschema.apptable;
213+
DROP TABLE appschema.apptable2;
214+
DROP SCHEMA appschema;
215+
REVOKE ALL ON DATABASE contrib_regression FROM user1, user2, users;
216+
DROP ROLE user1;
217+
DROP ROLE user2;
218+
DROP ROLE users;

pg_permissions--1.0.sql

Lines changed: 36 additions & 29 deletions
Original file line numberDiff line numberDiff line change
@@ -108,7 +108,7 @@ CREATE VIEW function_permissions AS
108108
SELECT obj_type 'FUNCTION' AS object_type,
109109
r.rolname AS role_name,
110110
f.pronamespace::regnamespace::name AS schema_name,
111-
f.oid::regprocedure::text AS object_name,
111+
regexp_replace(f.oid::regprocedure::text, '^((("[^"]*")|([^"][^.]*))\.)?', '') AS object_name,
112112
NULL::name AS column_name,
113113
perm_type 'EXECUTE' AS permission,
114114
has_function_privilege(r.oid, f.oid, 'EXECUTE') AS granted
@@ -217,7 +217,7 @@ CREATE FUNCTION permission_diffs()
217217
column_name name,
218218
permission perm_type
219219
)
220-
LANGUAGE plpgsql SET search_path FROM CURRENT STABLE AS
220+
LANGUAGE plpgsql SET search_path FROM CURRENT AS
221221
$$DECLARE
222222
typ obj_type;
223223
r name;
@@ -229,56 +229,63 @@ $$DECLARE
229229
so name;
230230
aso name;
231231
p perm_type;
232+
ap perm_type;
232233
g boolean;
233234
ag boolean;
234235
BEGIN
236+
/* temporary receptacle for reports */
237+
CREATE TEMPORARY TABLE findings (
238+
missing boolean,
239+
role_name name,
240+
object_type obj_type,
241+
schema_name name,
242+
object_name text,
243+
column_name name,
244+
permission perm_type
245+
) ON COMMIT DROP;
246+
247+
/* loop through all entries in "permission_target" */
235248
FOR r, p, typ, s, o, so IN
236249
SELECT pt.role_name, p.permission, pt.object_type, pt.schema_name, pt.object_name, pt.column_name
237250
FROM permission_target AS pt
238251
CROSS JOIN LATERAL unnest(pt.permissions) AS p(permission)
239252
LOOP
240-
FOR ar, a_s, ao, aso, ag IN
241-
SELECT ap.role_name, ap.schema_name, ap.object_name, ap.column_name, ap.granted
242-
FROM all_permissions AS ap
243-
WHERE ap.object_type = typ
244-
AND ap.permission = p
245-
AND (ap.schema_name = s OR s IS NULL)
246-
AND (ap.object_name = o OR o IS NULL)
247-
AND (ap.column_name = so OR so IS NULL)
253+
/* find all matching object permissions */
254+
FOR ar, ap, a_s, ao, aso, ag IN
255+
SELECT apm.role_name, apm.permission, apm.schema_name, apm.object_name, apm.column_name, apm.granted
256+
FROM all_permissions AS apm
257+
WHERE apm.object_type = typ
258+
AND (apm.schema_name = s OR s IS NULL)
259+
AND (apm.object_name = o OR o IS NULL)
260+
AND (apm.column_name = so OR so IS NULL)
248261
LOOP
249-
IF ar = r AND NOT ag THEN
262+
IF ar = r AND ap = p AND NOT ag THEN
250263
/* permission not granted that should be */
251-
permission_diffs.missing := TRUE;
252-
permission_diffs.role_name := r;
253-
permission_diffs.object_type := typ;
254-
permission_diffs.schema_name := a_s;
255-
permission_diffs.object_name := ao;
256-
permission_diffs.column_name := aso;
257-
permission_diffs.permission := p;
258-
RETURN NEXT;
264+
INSERT INTO findings
265+
(missing, role_name, object_type, schema_name, object_name, column_name, permission)
266+
VALUES (TRUE, r, typ, a_s, ao, aso, ap);
259267
END IF;
260-
IF ar <> r AND ag THEN
261-
/* permission granted to a different role, check if there is a rule */
268+
IF (ar <> r OR ap <> p) AND ag THEN
269+
/* different permission found, check if there is a matching rule */
262270
IF NOT EXISTS (
263271
SELECT 1
264272
FROM permission_target AS pt
265273
WHERE pt.role_name = ar
274+
AND pt.permissions @> ARRAY[ap]::perm_type[]
275+
AND pt.object_type = typ
266276
AND (pt.schema_name IS NULL OR pt.schema_name = a_s)
267277
AND (pt.object_name IS NULL OR pt.object_name = ao)
268278
AND (pt.column_name IS NULL OR pt.column_name = aso)
269279
)
270280
THEN
271281
/* extra permission found, report */
272-
permission_diffs.missing := FALSE;
273-
permission_diffs.role_name := ar;
274-
permission_diffs.object_type := typ;
275-
permission_diffs.schema_name := a_s;
276-
permission_diffs.object_name := ao;
277-
permission_diffs.column_name := aso;
278-
permission_diffs.permission := p;
279-
RETURN NEXT;
282+
INSERT INTO findings
283+
(missing, role_name, object_type, schema_name, object_name, column_name, permission)
284+
VALUES (FALSE, ar, typ, a_s, ao, aso, ap);
280285
END IF;
281286
END IF;
282287
END LOOP;
283288
END LOOP;
289+
290+
RETURN QUERY SELECT DISTINCT * FROM findings;
284291
END;$$;

0 commit comments

Comments
 (0)