-
Notifications
You must be signed in to change notification settings - Fork 16
/
pg_permissions--1.3.sql
451 lines (409 loc) · 15 KB
/
pg_permissions--1.3.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
-- complain if script is sourced in psql, rather than via CREATE EXTENSION
\echo Use "CREATE EXTENSION pg_permissions" to load this file. \quit
/* types */
CREATE TYPE perm_type AS ENUM (
'SELECT',
'INSERT',
'UPDATE',
'DELETE',
'TRUNCATE',
'REFERENCES',
'TRIGGER',
'USAGE',
'CREATE',
'EXECUTE',
'CONNECT',
'TEMPORARY',
'MAINTAIN'
);
CREATE TYPE obj_type AS ENUM (
'TABLE',
'VIEW',
'COLUMN',
'SEQUENCE',
'FUNCTION',
'SCHEMA',
'DATABASE'
);
/* views for the actual permissions */
CREATE VIEW table_permissions AS
SELECT obj_type 'TABLE' AS object_type,
r.rolname AS role_name,
t.relnamespace::regnamespace::name AS schema_name,
t.relname::text AS object_name,
NULL::name AS column_name,
p.perm::perm_type AS permission,
has_table_privilege(r.oid, t.oid, p.perm) AS granted
FROM pg_catalog.pg_class AS t
CROSS JOIN pg_catalog.pg_roles AS r
CROSS JOIN unnest(
CASE WHEN current_setting('server_version_num')::integer < 170000
THEN ARRAY['SELECT','INSERT','UPDATE','DELETE','TRUNCATE','REFERENCES','TRIGGER']
ELSE ARRAY['SELECT','INSERT','UPDATE','DELETE','TRUNCATE','REFERENCES','TRIGGER','MAINTAIN']
END
) AS p(perm)
WHERE t.relnamespace::regnamespace::name <> 'information_schema'
AND t.relnamespace::regnamespace::name NOT LIKE 'pg_%'
AND t.relkind = 'r'
AND NOT r.rolsuper;
GRANT SELECT ON table_permissions TO PUBLIC;
CREATE VIEW view_permissions AS
SELECT obj_type 'VIEW' AS object_type,
r.rolname AS role_name,
t.relnamespace::regnamespace::name AS schema_name,
t.relname::text AS object_name,
NULL::name AS column_name,
p.perm::perm_type AS permission,
has_table_privilege(r.oid, t.oid, p.perm) AS granted
FROM pg_catalog.pg_class AS t
CROSS JOIN pg_catalog.pg_roles AS r
CROSS JOIN unnest(
CASE WHEN current_setting('server_version_num')::integer < 170000
THEN ARRAY['SELECT','INSERT','UPDATE','DELETE','TRUNCATE','REFERENCES','TRIGGER']
ELSE ARRAY['SELECT','INSERT','UPDATE','DELETE','TRUNCATE','REFERENCES','TRIGGER','MAINTAIN']
END
) AS p(perm)
WHERE t.relnamespace::regnamespace::name <> 'information_schema'
AND t.relnamespace::regnamespace::name NOT LIKE 'pg_%'
AND t.relkind = 'v'
AND NOT r.rolsuper;
GRANT SELECT ON view_permissions TO PUBLIC;
CREATE VIEW column_permissions AS
SELECT obj_type 'COLUMN' AS object_type,
r.rolname AS role_name,
t.relnamespace::regnamespace::name AS schema_name,
t.relname::text AS object_name,
c.attname AS column_name,
p.perm::perm_type AS permission,
has_column_privilege(r.oid, t.oid, c.attnum, p.perm)
AND NOT has_table_privilege(r.oid, t.oid, p.perm) AS granted
FROM pg_catalog.pg_class AS t
JOIN pg_catalog.pg_attribute AS c ON t.oid = c.attrelid
CROSS JOIN pg_catalog.pg_roles AS r
CROSS JOIN (VALUES ('SELECT'), ('INSERT'), ('UPDATE'), ('REFERENCES')) AS p(perm)
WHERE t.relnamespace::regnamespace::name <> 'information_schema'
AND t.relnamespace::regnamespace::name NOT LIKE 'pg_%'
AND c.attnum > 0 AND NOT c.attisdropped
AND t.relkind IN ('r', 'v')
AND NOT r.rolsuper;
GRANT SELECT ON column_permissions TO PUBLIC;
CREATE VIEW sequence_permissions AS
SELECT obj_type 'SEQUENCE' AS object_type,
r.rolname AS role_name,
t.relnamespace::regnamespace::name AS schema_name,
t.relname::text AS object_name,
NULL::name AS column_name,
p.perm::perm_type AS permission,
has_sequence_privilege(r.oid, t.oid, p.perm) AS granted
FROM pg_catalog.pg_class AS t
CROSS JOIN pg_catalog.pg_roles AS r
CROSS JOIN (VALUES ('SELECT'), ('USAGE'), ('UPDATE')) AS p(perm)
WHERE t.relnamespace::regnamespace::name <> 'information_schema'
AND t.relnamespace::regnamespace::name NOT LIKE 'pg_%'
AND t.relkind = 'S'
AND NOT r.rolsuper;
GRANT SELECT ON sequence_permissions TO PUBLIC;
CREATE VIEW function_permissions AS
SELECT obj_type 'FUNCTION' AS object_type,
r.rolname AS role_name,
f.pronamespace::regnamespace::name AS schema_name,
regexp_replace(f.oid::regprocedure::text, '^((("[^"]*")|([^"][^.]*))\.)?', '') AS object_name,
NULL::name AS column_name,
perm_type 'EXECUTE' AS permission,
has_function_privilege(r.oid, f.oid, 'EXECUTE') AS granted
FROM pg_catalog.pg_proc f
CROSS JOIN pg_catalog.pg_roles AS r
WHERE f.pronamespace::regnamespace::name <> 'information_schema'
AND f.pronamespace::regnamespace::name NOT LIKE 'pg_%'
AND NOT r.rolsuper;
GRANT SELECT ON function_permissions TO PUBLIC;
CREATE VIEW schema_permissions AS
SELECT obj_type 'SCHEMA' AS object_type,
r.rolname AS role_name,
n.nspname AS schema_name,
NULL::text AS object_name,
NULL::name AS column_name,
p.perm::perm_type AS permission,
has_schema_privilege(r.oid, n.oid, p.perm) AS granted
FROM pg_catalog.pg_namespace AS n
CROSS JOIN pg_catalog.pg_roles AS r
CROSS JOIN (VALUES ('USAGE'), ('CREATE')) AS p(perm)
WHERE n.nspname <> 'information_schema'
AND n.nspname NOT LIKE 'pg_%'
AND NOT r.rolsuper;
GRANT SELECT ON schema_permissions TO PUBLIC;
CREATE VIEW database_permissions AS
WITH list AS (SELECT unnest AS perm
FROM unnest ('{"CREATE", "CONNECT", "TEMPORARY"}'::text[]))
SELECT obj_type 'DATABASE' AS object_type,
r.rolname AS role_name,
NULL::name AS schema_name,
NULL::text AS object_name,
NULL::name AS column_name,
p.perm::perm_type AS permission,
has_database_privilege(r.oid, d.oid, p.perm) AS granted
FROM pg_catalog.pg_database AS d
CROSS JOIN pg_catalog.pg_roles AS r
CROSS JOIN (VALUES ('CREATE'), ('CONNECT'), ('TEMPORARY')) AS p(perm)
WHERE d.datname = current_database()
AND NOT r.rolsuper;
GRANT SELECT ON database_permissions TO PUBLIC;
CREATE VIEW all_permissions AS
SELECT * FROM table_permissions
UNION ALL
SELECT * FROM view_permissions
UNION ALL
SELECT * FROM column_permissions
UNION ALL
SELECT * FROM sequence_permissions
UNION ALL
SELECT * FROM function_permissions
UNION ALL
SELECT * FROM schema_permissions
UNION ALL
SELECT * FROM database_permissions;
GRANT SELECT ON all_permissions TO PUBLIC;
/* update trigers for the views */
CREATE FUNCTION permissions_trigger_func()
RETURNS TRIGGER
LANGUAGE plpgsql
AS $$
DECLARE
db_name text;
cmd text;
BEGIN
IF NEW.object_type <> OLD.object_type OR
NEW.role_name <> OLD.role_name OR
NEW.schema_name <> OLD.schema_name OR
NEW.object_name <> OLD.object_name OR
NEW.column_name <> OLD.column_name OR
NEW.permission <> OLD.permission
THEN
RAISE 'Only the "granted" column may be updated';
END IF;
-- Is there anything to do at all?
IF NEW.granted = OLD.granted
THEN
RETURN NEW;
END IF;
IF OLD.object_type IN ('TABLE', 'VIEW')
THEN
IF NOT OLD.granted
THEN
cmd := format('GRANT %s ON %s.%s TO %s',
OLD.permission, OLD.schema_name,
OLD.object_name, OLD.role_name);
ELSE
cmd := format('REVOKE %s ON %s.%s FROM %s',
OLD.permission, OLD.schema_name,
OLD.object_name, OLD.role_name);
END IF;
ELSIF OLD.object_type = 'COLUMN'
THEN
IF NOT OLD.granted
THEN
cmd := format('GRANT %s(%s) ON %s.%s TO %s',
OLD.permission, OLD.column_name,
OLD.schema_name, OLD.object_name,
OLD.role_name);
ELSE
cmd := format('REVOKE %s(%s) ON %s.%s FROM %s',
OLD.permission, OLD.column_name,
OLD.schema_name, OLD.object_name,
OLD.role_name);
END IF;
ELSIF OLD.object_type = 'SEQUENCE'
THEN
IF NOT OLD.granted
THEN
cmd := format('GRANT %s ON SEQUENCE %s.%s TO %s',
OLD.permission, OLD.schema_name,
OLD.object_name, OLD.role_name);
ELSE
cmd := format('REVOKE %s ON SEQUENCE %s.%s FROM %s',
OLD.permission, OLD.schema_name,
OLD.object_name, OLD.role_name);
END IF;
ELSIF OLD.object_type = 'FUNCTION'
THEN
IF NOT OLD.granted
THEN
cmd := format('GRANT %s ON FUNCTION %s.%s TO %s',
OLD.permission, OLD.schema_name,
OLD.object_name, OLD.role_name);
ELSE
cmd := format('REVOKE %s ON FUNCTION %s.%s FROM %s',
OLD.permission, OLD.schema_name,
OLD.object_name, OLD.role_name);
END IF;
ELSIF OLD.object_type = 'SCHEMA'
THEN
IF NOT OLD.granted
THEN
cmd := format('GRANT %s ON SCHEMA %s TO %s',
OLD.permission, OLD.schema_name,
OLD.role_name);
ELSE
cmd := format('REVOKE %s ON SCHEMA %s FROM %s',
OLD.permission, OLD.schema_name,
OLD.role_name);
END IF;
ELSIF OLD.object_type = 'DATABASE'
THEN
db_name := pg_catalog.current_database();
IF NOT OLD.granted
THEN
cmd := format('GRANT %s ON DATABASE %s TO %s',
OLD.permission, db_name, OLD.role_name);
ELSE
cmd := format('REVOKE %s ON DATABASE %s FROM %s',
OLD.permission, db_name, OLD.role_name);
END IF;
ELSE
RAISE 'Unrecognized object type: %',
OLD.object_type;
END IF;
EXECUTE cmd;
RETURN NEW;
END;
$$;
CREATE TRIGGER permissions_trigger
INSTEAD OF UPDATE ON table_permissions
FOR EACH ROW EXECUTE PROCEDURE permissions_trigger_func();
CREATE TRIGGER permissions_trigger
INSTEAD OF UPDATE ON column_permissions
FOR EACH ROW EXECUTE PROCEDURE permissions_trigger_func();
CREATE TRIGGER permissions_trigger
INSTEAD OF UPDATE ON view_permissions
FOR EACH ROW EXECUTE PROCEDURE permissions_trigger_func();
CREATE TRIGGER permissions_trigger
INSTEAD OF UPDATE ON sequence_permissions
FOR EACH ROW EXECUTE PROCEDURE permissions_trigger_func();
CREATE TRIGGER permissions_trigger
INSTEAD OF UPDATE ON function_permissions
FOR EACH ROW EXECUTE PROCEDURE permissions_trigger_func();
CREATE TRIGGER permissions_trigger
INSTEAD OF UPDATE ON schema_permissions
FOR EACH ROW EXECUTE PROCEDURE permissions_trigger_func();
CREATE TRIGGER permissions_trigger
INSTEAD OF UPDATE ON database_permissions
FOR EACH ROW EXECUTE PROCEDURE permissions_trigger_func();
CREATE TRIGGER permissions_trigger
INSTEAD OF UPDATE ON all_permissions
FOR EACH ROW EXECUTE PROCEDURE permissions_trigger_func();
/* table for the targeted permissions */
CREATE TABLE permission_target (
id int4 PRIMARY KEY,
role_name name NOT NULL,
permissions perm_type[] NOT NULL,
object_type obj_type NOT NULL,
schema_name name,
object_name text,
column_name name,
CONSTRAINT permission_target_valid
CHECK (CASE WHEN object_type = 'DATABASE'
THEN schema_name IS NULL AND object_name IS NULL AND column_name IS NULL
AND ARRAY['CONNECT','CREATE','TEMPORARY']::perm_type[] @> permissions
WHEN object_type = 'SCHEMA'
THEN object_name IS NULL AND column_name IS NULL
AND ARRAY['CREATE','USAGE']::perm_type[] @> permissions
WHEN object_type IN ('TABLE', 'VIEW')
THEN column_name IS NULL
AND ARRAY['SELECT','INSERT','UPDATE','DELETE','TRUNCATE','REFERENCES','TRIGGER','MAINTAIN']::perm_type[] @> permissions
WHEN object_type = 'SEQUENCE'
THEN column_name IS NULL
AND ARRAY['SELECT','USAGE','UPDATE']::perm_type[] @> permissions
WHEN object_type = 'FUNCTION'
THEN column_name IS NULL
AND ARRAY['EXECUTE']::perm_type[] @> permissions
WHEN object_type = 'COLUMN'
THEN ARRAY['SELECT','INSERT','UPDATE','REFERENCES']::perm_type[] @> permissions
END)
);
CREATE SEQUENCE permission_target_id_seq OWNED BY permission_target.id;
ALTER TABLE permission_target ALTER id
SET DEFAULT nextval('permission_target_id_seq'::regclass);
GRANT SELECT, INSERT, UPDATE, DELETE ON permission_target TO PUBLIC;
GRANT USAGE ON SEQUENCE permission_target_id_seq TO PUBLIC;
SELECT pg_catalog.pg_extension_config_dump('permission_target', '');
SELECT pg_catalog.pg_extension_config_dump('permission_target_id_seq', '');
CREATE FUNCTION permission_diffs()
RETURNS TABLE (
missing boolean,
role_name name,
object_type obj_type,
schema_name name,
object_name text,
column_name name,
permission perm_type
)
LANGUAGE plpgsql SET search_path FROM CURRENT AS
$$DECLARE
typ obj_type;
r name;
ar name;
s name;
a_s name;
o text;
ao text;
so name;
aso name;
p perm_type;
ap perm_type;
g boolean;
ag boolean;
BEGIN
/* temporary receptacle for reports */
CREATE TEMPORARY TABLE findings (
missing boolean,
role_name name,
object_type obj_type,
schema_name name,
object_name text,
column_name name,
permission perm_type
) ON COMMIT DROP;
/* loop through all entries in "permission_target" */
FOR r, p, typ, s, o, so IN
SELECT pt.role_name, p.permission, pt.object_type, pt.schema_name, pt.object_name, pt.column_name
FROM permission_target AS pt
CROSS JOIN LATERAL unnest(pt.permissions) AS p(permission)
LOOP
/* find all matching object permissions */
FOR ar, ap, a_s, ao, aso, ag IN
SELECT apm.role_name, apm.permission, apm.schema_name, apm.object_name, apm.column_name, apm.granted
FROM all_permissions AS apm
WHERE apm.object_type = typ
AND (apm.schema_name = s OR s IS NULL)
AND (apm.object_name = o OR o IS NULL)
AND (apm.column_name = so OR so IS NULL)
LOOP
IF ar = r AND ap = p AND NOT ag THEN
/* permission not granted that should be */
INSERT INTO findings
(missing, role_name, object_type, schema_name, object_name, column_name, permission)
VALUES (TRUE, r, typ, a_s, ao, aso, ap);
END IF;
IF (ar <> r OR ap <> p) AND ag THEN
/* different permission found, check if there is a matching rule */
IF NOT EXISTS (
SELECT 1
FROM permission_target AS pt
WHERE pt.role_name = ar
AND pt.permissions @> ARRAY[ap]::perm_type[]
AND pt.object_type = typ
AND (pt.schema_name IS NULL OR pt.schema_name = a_s)
AND (pt.object_name IS NULL OR pt.object_name = ao)
AND (pt.column_name IS NULL OR pt.column_name = aso)
)
THEN
/* extra permission found, report */
INSERT INTO findings
(missing, role_name, object_type, schema_name, object_name, column_name, permission)
VALUES (FALSE, ar, typ, a_s, ao, aso, ap);
END IF;
END IF;
END LOOP;
END LOOP;
RETURN QUERY SELECT DISTINCT * FROM findings;
END;$$;