pax_global_header00006660000000000000000000000064146323102660014515gustar00rootroot0000000000000052 comment=d5d1a190562ab231e2642f08c1090a86224b54f3 pg_permissions-REL_1_3/000077500000000000000000000000001463231026600152045ustar00rootroot00000000000000pg_permissions-REL_1_3/.github/000077500000000000000000000000001463231026600165445ustar00rootroot00000000000000pg_permissions-REL_1_3/.github/workflows/000077500000000000000000000000001463231026600206015ustar00rootroot00000000000000pg_permissions-REL_1_3/.github/workflows/regression.yml000066400000000000000000000014661463231026600235130ustar00rootroot00000000000000name: Build on: [push, pull_request] jobs: build: runs-on: ubuntu-latest defaults: run: shell: sh strategy: matrix: pgversion: - 16 - 15 - 14 - 13 - 12 env: PGVERSION: ${{ matrix.pgversion }} steps: - name: checkout uses: actions/checkout@v4 - name: install pg run: | sudo /usr/share/postgresql-common/pgdg/apt.postgresql.org.sh -v $PGVERSION -p -i sudo -u postgres createuser -s "$USER" - name: install extension run: | sudo -E make install - name: test run: | sudo pg_ctlcluster $PGVERSION main restart make installcheck - name: show regression diffs if: ${{ failure() }} run: | cat regression.diffs pg_permissions-REL_1_3/.gitignore000066400000000000000000000000451463231026600171730ustar00rootroot00000000000000results regression.* !regression.yml pg_permissions-REL_1_3/CHANGELOG000066400000000000000000000011531463231026600164160ustar00rootroot00000000000000Version 1.3, released 2024-06-12 Enhancements: - Support the MAINTAINprivilege new in PostgreSQL v17. Version 1.2, released 2024-02-16 Enhancements: - Add sequence to "permission_target" for ease of use. Idea by Srikanth Medikonda. Version 1.1, released 2018-12-19 Enhancements: - Add triggers to the permission views to make them updatable. Updating will issue GRANT or REVOKE statements. Patch by Antonin Houska. Bugfixes: - Rename the "permissions" column of "schema_permissions" and "database_permissions" to "permission" to match the other views. Version 1.0, released 2018-10-18 - first release pg_permissions-REL_1_3/LICENSE000066400000000000000000000017461463231026600162210ustar00rootroot00000000000000Copyright (c) 2018-2023, CYBERTEC PostgreSQL International GmbH Permission to use, copy, modify, and distribute this software and its documentation for any purpose, without fee, and without a written agreement is hereby granted, provided that the above copyright notice and this paragraph and the following two paragraphs appear in all copies. IN NO EVENT SHALL THE COPYRIGHT HOLDER BE LIABLE TO ANY PARTY FOR DIRECT, INDIRECT, SPECIAL, INCIDENTAL, OR CONSEQUENTIAL DAMAGES, INCLUDING LOST PROFITS, ARISING OUT OF THE USE OF THIS SOFTWARE AND ITS DOCUMENTATION, EVEN IF THE COPYRIGHT HOLDER HAS BEEN ADVISED OF THE POSSIBILITY OF SUCH DAMAGE. THE COPYRIGHT HOLDER SPECIFICALLY DISCLAIMS ANY WARRANTIES, INCLUDING, BUT NOT LIMITED TO, THE IMPLIED WARRANTIES OF MERCHANTABILITY AND FITNESS FOR A PARTICULAR PURPOSE. THE SOFTWARE PROVIDED HEREUNDER IS ON AN "AS IS" BASIS, AND CYBERTEC International GmbH HAS NO OBLIGATIONS TO PROVIDE MAINTENANCE, SUPPORT, UPDATES, ENHANCEMENTS, OR MODIFICATIONS. pg_permissions-REL_1_3/Makefile000066400000000000000000000002621463231026600166440ustar00rootroot00000000000000EXTENSION = pg_permissions DATA = pg_permissions--*.sql DOCS = README.pg_permissions REGRESS = sample PG_CONFIG = pg_config PGXS := $(shell $(PG_CONFIG) --pgxs) include $(PGXS) pg_permissions-REL_1_3/README.md000066400000000000000000000144711463231026600164720ustar00rootroot00000000000000PostgreSQL permission reports and checks ======================================== This extension allows you to review object permissions on a PostgreSQL database. Cookbook -------- First, you have to install the extension in the database: CREATE EXTENSION pg_permissions SCHEMA public; Then you need to add entries to `permission_target` that correspond to your desired permissions. Let's assume we have a schema `appschema`, and `appuser` should have `SELECT`, `UPDATE`, `DELETE` and `INSERT` permissions on all tables and views in that schema: INSERT INTO public.permission_target (role_name, permissions, object_type, schema_name) VALUES ('appuser', '{SELECT,INSERT,UPDATE,DELETE}', 'TABLE', 'appschema'); INSERT INTO public.permission_target (role_name, permissions, object_type, schema_name) VALUES ('appuser', '{SELECT,INSERT,UPDATE,DELETE}', 'VIEW', 'appschema'); Of course, the user will need the `USAGE` privilege on the schema: INSERT INTO public.permission_target (role_name, permissions, object_type, schema_name) VALUES ('appuser', '{USAGE}', 'SCHEMA', 'appschema'); The user also needs `USAGE` privileges on the `appseq` sequence in that schema: INSERT INTO public.permission_target (role_name, permissions, object_type, schema_name, object_name) VALUES ('appuser', '{USAGE}', 'SEQUENCE', 'appschema', 'appseq'); Now we can review which permissions are missing and which additional permissions are granted: SELECT * FROM public.permission_diffs(); missing | role_name | object_type | schema_name | object_name | column_name | permission ---------+-----------+-------------+-------------+-------------+-------------+------------ f | laurenz | VIEW | appschema | appview | | SELECT t | appuser | TABLE | appschema | apptable | | DELETE (2 rows) That means that `appuser` is missing the `DELETE` privilege on `appschema.apptable` which should be granted, while user `laurenz` has the additional `SELECT` privilege on `appschema.appview` (`missing` is `FALSE`). To review the actual permissions on an object, we can use the `*_permissions` views: SELECT * FROM schema_permissions WHERE role_name = 'appuser' AND schema_name = 'appschema'; object_type | role_name | schema_name | object_name | column_name | permissions | granted -------------+-----------+-------------+-------------+-------------+-------------+--------- SCHEMA | appuser | appschema | | | USAGE | t SCHEMA | appuser | appschema | | | CREATE | f (2 rows) Usage ----- ### Views ### The extension provides a number of views: - `database_permissions`: permissions granted on the current database - `schema_permissions`: permissions granted on schemas - `table_permissions`: permissions granted on tables - `view_permissions`: permissions granted on views - `column_permissions`: permissions granted on table and view columns - `function_permissions`: permissions granted on functions - `sequence_permissions`: permissions granted on sequences - `all_permissions`: permissions on all objects (`UNION` of the above) All views have the same columns; a column is NULL if it has no meaning for the current view. These views can be used to examine the currently granted permissions on database objects. The `granted` column of these views can be updated, which causes the appropriate `GRANT` or `REVOKE` command to be executed. **Note:** Superusers are not shown in the views, as they automatically have all permissions. ### Tables ### The extension provides a table `permission_target` with which you can describe the permissions that *should* be granted on database objects. If you set a relevant column in `permission_target` to NULL (e.g., the `object_name` and `column_name` columns in a `TABLE` entry), the meaning is that the entry refers to *all* possible objects (in the example above, all tables in the schema). ### Functions ### The table function `permission_diffs()` checks the desired permissions in `permission_target` against the actually granted permissions in the views of the extension and returns a table of differences. If the first column `missing` is `TRUE`, the result is a permission that should be there but isn't; if `missing` is `FALSE`, the result row is a permission that is there even though it is not defined in `permission_target` (an extra permission). Installation ------------ Make sure the PostgreSQL extension building infrastructure is installed. If you installed PostgreSQL with installation packages, you usually need to install the "development"-Package. Make sure that `pg_config` is on your `PATH`. Then type make install Then connect to the database where you want to run `pg_permissions` and use CREATE EXTENSION pg_permissions; To upgrade from an older version of the extension, run ALTER EXTENSION pg_permissions UPDATE; You need `CREATE` privileges on the schema where you install the extension. Note that you won't be able to upgrade the extension from version 1.2 or earlier to 1.3 or later for technical reasons (an added enumeration value for the `MAINTAIN` privilege). You will have to drop and re-create the extension to upgrade to 1.3 or later from an earlier release. Don't forget to dump the contents of `permission_target` before you do that, so that you can restore them afterwards. ### Installation without the extension building infrastructure ### This is also what Windows users will have to do because there is no extension building infrastructure for Windows. Find out where your PostgreSQL share directory is: pg_config --sharedir Then copy `pg_permissions.control` and the SQL files to the `extension` subdirectory of that directory, e.g. copy pg_permissions.control *.sql "C:\Program Files\PostgreSQL\10\share\extension" You still have to run `CREATE EXTENSION` as described above. Support ------- Open an [issue][issue] on GitHub if you have problems or questions. For professional support, please contact [CYBERTEC PostgreSQL International GmbH][cybertec]. [issue]: https://github.com/cybertec-postgresql/pg_permissions/issues [cybertec]: https://www.cybertec-postgresql.com/ pg_permissions-REL_1_3/README.pg_permissions000077700000000000000000000000001463231026600223762README.mdustar00rootroot00000000000000pg_permissions-REL_1_3/expected/000077500000000000000000000000001463231026600170055ustar00rootroot00000000000000pg_permissions-REL_1_3/expected/sample.out000066400000000000000000000336721463231026600210320ustar00rootroot00000000000000CREATE EXTENSION pg_permissions; /* test roles (will be removed afterwards) */ CREATE ROLE users; CREATE ROLE user1 LOGIN IN ROLE users; CREATE ROLE user2 LOGIN IN ROLE users; /* database */ -- desired permissions INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('users', ARRAY['CONNECT','TEMPORARY']::perm_type[], 'DATABASE', NULL, NULL, NULL), ('user1', ARRAY['CONNECT','TEMPORARY']::perm_type[], 'DATABASE', NULL, NULL, NULL), ('user2', ARRAY['CONNECT','TEMPORARY']::perm_type[], 'DATABASE', NULL, NULL, NULL); -- this should fail INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('user2', ARRAY['CREATE']::perm_type[], 'DATABASE', 'public', NULL, NULL); ERROR: new row for relation "permission_target" violates check constraint "permission_target_valid" DETAIL: Failing row contains (4, user2, {CREATE}, DATABASE, public, null, null). -- actual permissions REVOKE ALL ON DATABASE contrib_regression FROM PUBLIC; GRANT CONNECT, TEMPORARY ON DATABASE contrib_regression TO users; GRANT CREATE ON DATABASE contrib_regression TO user2; -- too much /* schema */ -- desired permissions INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('users', ARRAY['USAGE']::perm_type[], 'SCHEMA', 'appschema', NULL, NULL), ('user1', ARRAY['USAGE','CREATE']::perm_type[], 'SCHEMA', 'appschema', NULL, NULL), ('user2', ARRAY['USAGE']::perm_type[], 'SCHEMA', 'appschema', NULL, NULL); -- this should fail INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('user2', ARRAY['CREATE']::perm_type[], 'SCHEMA', 'appschema', 'sometable', NULL); ERROR: new row for relation "permission_target" violates check constraint "permission_target_valid" DETAIL: Failing row contains (8, user2, {CREATE}, SCHEMA, appschema, sometable, null). -- actual permissions CREATE SCHEMA appschema; GRANT USAGE ON SCHEMA appschema TO PUBLIC; -- missing CREATE for user1 GRANT CREATE ON SCHEMA appschema TO user2; -- too much /* table */ -- desired permissions INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('user1', ARRAY['SELECT','INSERT','UPDATE','DELETE']::perm_type[], 'TABLE', 'appschema', NULL, NULL), ('user2', ARRAY['SELECT']::perm_type[], 'TABLE', 'appschema', NULL, NULL); -- this should fail INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('user2', ARRAY['INSERT']::perm_type[], 'TABLE', 'appschema', 'apptable', 'acolumn'); ERROR: new row for relation "permission_target" violates check constraint "permission_target_valid" DETAIL: Failing row contains (11, user2, {INSERT}, TABLE, appschema, apptable, acolumn). -- actual permissions CREATE TABLE appschema.apptable ( id integer PRIMARY KEY, val text NOT NULL, created timestamp with time zone NOT NULL DEFAULT current_timestamp ); CREATE TABLE appschema.apptable2 ( id integer PRIMARY KEY, val text NOT NULL, created timestamp with time zone NOT NULL DEFAULT current_timestamp ); -- missing all permissions on this one GRANT SELECT, INSERT, UPDATE ON appschema.apptable TO user1; -- missing DELETE GRANT SELECT, INSERT ON appschema.apptable TO user2; -- extra privilege INSERT /* column */ -- desired permissions INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('user1', ARRAY['SELECT','INSERT','UPDATE','REFERENCES']::perm_type[], 'COLUMN', 'appschema', 'apptable2', 'val'); -- this should fail INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('user2', ARRAY['DELETE']::perm_type[], 'COLUMN', 'appschema', 'apptable2', 'val'); ERROR: new row for relation "permission_target" violates check constraint "permission_target_valid" DETAIL: Failing row contains (13, user2, {DELETE}, COLUMN, appschema, apptable2, val). -- actual permissions -- missing REFERENCES for user1 on apptable2.val GRANT UPDATE (val) ON appschema.apptable2 TO user2; -- extra privilege UPDATE /* view */ -- desired permissions INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('user1', ARRAY['SELECT','INSERT','UPDATE','DELETE']::perm_type[], 'VIEW', 'appschema', 'appview', NULL), ('user2', ARRAY['SELECT']::perm_type[], 'VIEW', 'appschema', 'appview', NULL); -- actual permissions CREATE VIEW appschema.appview AS SELECT id, val FROM appschema.apptable; GRANT SELECT ON appschema.appview TO users; -- extra permission to "users" GRANT INSERT, DELETE ON appschema.appview TO user1; -- missing UPDATE /* sequence */ -- desired permissions INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('users', ARRAY['USAGE']::perm_type[], 'SEQUENCE', 'appschema', 'appseq', NULL), ('user1', ARRAY['USAGE','SELECT']::perm_type[], 'SEQUENCE', 'appschema', 'appseq', NULL), ('user2', ARRAY['USAGE']::perm_type[], 'SEQUENCE', 'appschema', 'appseq', NULL); -- actual permissions CREATE SEQUENCE appschema.appseq; GRANT USAGE ON SEQUENCE appschema.appseq TO users; -- missing SELECT for user1 GRANT UPDATE ON SEQUENCE appschema.appseq TO user2; -- extra permission UPDATE /* function */ -- desired permissions INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('user1', ARRAY['EXECUTE']::perm_type[], 'FUNCTION', 'appschema', 'appfun(integer)', NULL), ('user2', ARRAY['EXECUTE']::perm_type[], 'FUNCTION', 'appschema', 'appfun(integer)', NULL); -- this should fail INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('users', ARRAY['UPDATE']::perm_type[], 'FUNCTION', 'appschema', 'appfun(integer)', NULL); ERROR: new row for relation "permission_target" violates check constraint "permission_target_valid" DETAIL: Failing row contains (21, users, {UPDATE}, FUNCTION, appschema, appfun(integer), null). -- actual permissions CREATE FUNCTION appschema.appfun(i integer) RETURNS integer LANGUAGE sql IMMUTABLE AS 'SELECT i + 2'; -- extra permission for "users" /* report all permissions */ SELECT object_type, role_name, schema_name, object_name, column_name, permission FROM all_permissions WHERE granted AND role_name IN ('users', 'user1', 'user2') AND coalesce(schema_name, 'appschema') = 'appschema' ORDER BY object_type, role_name, schema_name, object_name, column_name, permission; object_type | role_name | schema_name | object_name | column_name | permission -------------+-----------+-------------+-----------------+-------------+------------ TABLE | user1 | appschema | apptable | | SELECT TABLE | user1 | appschema | apptable | | INSERT TABLE | user1 | appschema | apptable | | UPDATE TABLE | user2 | appschema | apptable | | SELECT TABLE | user2 | appschema | apptable | | INSERT VIEW | user1 | appschema | appview | | SELECT VIEW | user1 | appschema | appview | | INSERT VIEW | user1 | appschema | appview | | DELETE VIEW | user2 | appschema | appview | | SELECT VIEW | users | appschema | appview | | SELECT COLUMN | user2 | appschema | apptable2 | val | UPDATE SEQUENCE | user1 | appschema | appseq | | USAGE SEQUENCE | user2 | appschema | appseq | | UPDATE SEQUENCE | user2 | appschema | appseq | | USAGE SEQUENCE | users | appschema | appseq | | USAGE FUNCTION | user1 | appschema | appfun(integer) | | EXECUTE FUNCTION | user2 | appschema | appfun(integer) | | EXECUTE FUNCTION | users | appschema | appfun(integer) | | EXECUTE SCHEMA | user1 | appschema | | | USAGE SCHEMA | user2 | appschema | | | USAGE SCHEMA | user2 | appschema | | | CREATE SCHEMA | users | appschema | | | USAGE DATABASE | user1 | | | | CONNECT DATABASE | user1 | | | | TEMPORARY DATABASE | user2 | | | | CREATE DATABASE | user2 | | | | CONNECT DATABASE | user2 | | | | TEMPORARY DATABASE | users | | | | CONNECT DATABASE | users | | | | TEMPORARY (29 rows) /* report differences */ SELECT * FROM permission_diffs() WHERE role_name IN ('users', 'user1', 'user2') ORDER BY object_type, schema_name, object_name, column_name, role_name, permission, missing; missing | role_name | object_type | schema_name | object_name | column_name | permission ---------+-----------+-------------+-------------+-----------------+-------------+------------ t | user1 | TABLE | appschema | apptable | | DELETE f | user2 | TABLE | appschema | apptable | | INSERT t | user1 | TABLE | appschema | apptable2 | | SELECT t | user1 | TABLE | appschema | apptable2 | | INSERT t | user1 | TABLE | appschema | apptable2 | | UPDATE t | user1 | TABLE | appschema | apptable2 | | DELETE t | user2 | TABLE | appschema | apptable2 | | SELECT t | user1 | VIEW | appschema | appview | | UPDATE f | users | VIEW | appschema | appview | | SELECT t | user1 | COLUMN | appschema | apptable2 | val | SELECT t | user1 | COLUMN | appschema | apptable2 | val | INSERT t | user1 | COLUMN | appschema | apptable2 | val | UPDATE t | user1 | COLUMN | appschema | apptable2 | val | REFERENCES f | user2 | COLUMN | appschema | apptable2 | val | UPDATE t | user1 | SEQUENCE | appschema | appseq | | SELECT f | user2 | SEQUENCE | appschema | appseq | | UPDATE f | users | FUNCTION | appschema | appfun(integer) | | EXECUTE t | user1 | SCHEMA | appschema | | | CREATE f | user2 | SCHEMA | appschema | | | CREATE f | user2 | DATABASE | | | | CREATE (20 rows) /* fix some of the differences */ UPDATE column_permissions SET granted = TRUE WHERE role_name = 'user1' AND schema_name = 'appschema' AND object_name = 'apptable2' AND column_name = 'val' AND permission = 'REFERENCES'; UPDATE all_permissions SET granted = FALSE WHERE object_type = 'TABLE' AND role_name = 'user2' AND schema_name = 'appschema' AND object_name = 'apptable' AND permission = 'INSERT'; /* check the fixed permissions */ SELECT * FROM permission_diffs() WHERE role_name IN ('users', 'user1', 'user2') ORDER BY object_type, schema_name, object_name, column_name, role_name, permission, missing; missing | role_name | object_type | schema_name | object_name | column_name | permission ---------+-----------+-------------+-------------+-----------------+-------------+------------ t | user1 | TABLE | appschema | apptable | | DELETE t | user1 | TABLE | appschema | apptable2 | | SELECT t | user1 | TABLE | appschema | apptable2 | | INSERT t | user1 | TABLE | appschema | apptable2 | | UPDATE t | user1 | TABLE | appschema | apptable2 | | DELETE t | user2 | TABLE | appschema | apptable2 | | SELECT t | user1 | VIEW | appschema | appview | | UPDATE f | users | VIEW | appschema | appview | | SELECT t | user1 | COLUMN | appschema | apptable2 | val | SELECT t | user1 | COLUMN | appschema | apptable2 | val | INSERT t | user1 | COLUMN | appschema | apptable2 | val | UPDATE f | user2 | COLUMN | appschema | apptable2 | val | UPDATE t | user1 | SEQUENCE | appschema | appseq | | SELECT f | user2 | SEQUENCE | appschema | appseq | | UPDATE f | users | FUNCTION | appschema | appfun(integer) | | EXECUTE t | user1 | SCHEMA | appschema | | | CREATE f | user2 | SCHEMA | appschema | | | CREATE f | user2 | DATABASE | | | | CREATE (18 rows) /* clean up */ DROP FUNCTION appschema.appfun(integer); DROP VIEW appschema.appview; DROP SEQUENCE appschema.appseq; DROP TABLE appschema.apptable; DROP TABLE appschema.apptable2; DROP SCHEMA appschema; REVOKE ALL ON DATABASE contrib_regression FROM user1, user2, users; DROP ROLE user1; DROP ROLE user2; DROP ROLE users; pg_permissions-REL_1_3/pg_permissions--1.0--1.1.sql000066400000000000000000000140411463231026600217110ustar00rootroot00000000000000-- complain if script is sourced in psql, rather than via CREATE EXTENSION \echo Use "ALTER EXTENSION pg_permissions UPDATE" to load this file. \quit /* rename some view columns to match the other views */ DROP VIEW all_permissions; DROP VIEW schema_permissions; DROP VIEW database_permissions; 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(); pg_permissions-REL_1_3/pg_permissions--1.0.sql000066400000000000000000000240641463231026600213450ustar00rootroot00000000000000-- 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' ); 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 (VALUES (TEXT 'SELECT'), ('INSERT'), ('UPDATE'), ('DELETE'), ('TRUNCATE'), ('REFERENCES'), ('TRIGGER')) 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 (VALUES (TEXT 'SELECT'), ('INSERT'), ('UPDATE'), ('DELETE'), ('TRUNCATE'), ('REFERENCES'), ('TRIGGER')) 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 permissions, 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 permissions, 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; /* 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']::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) ); GRANT SELECT, INSERT, UPDATE, DELETE ON permission_target TO PUBLIC; SELECT pg_catalog.pg_extension_config_dump('permission_target', ''); 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;$$; pg_permissions-REL_1_3/pg_permissions--1.1--1.2.sql000066400000000000000000000007161463231026600217170ustar00rootroot00000000000000-- complain if script is sourced in psql, rather than via CREATE EXTENSION \echo Use "ALTER EXTENSION pg_permissions UPDATE" to load this file. \quit 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 USAGE ON SEQUENCE permission_target_id_seq TO PUBLIC; SELECT pg_catalog.pg_extension_config_dump('permission_target_id_seq', ''); pg_permissions-REL_1_3/pg_permissions--1.1.sql000066400000000000000000000343351463231026600213500ustar00rootroot00000000000000-- 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' ); 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 (VALUES (TEXT 'SELECT'), ('INSERT'), ('UPDATE'), ('DELETE'), ('TRUNCATE'), ('REFERENCES'), ('TRIGGER')) 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 (VALUES (TEXT 'SELECT'), ('INSERT'), ('UPDATE'), ('DELETE'), ('TRUNCATE'), ('REFERENCES'), ('TRIGGER')) 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']::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) ); GRANT SELECT, INSERT, UPDATE, DELETE ON permission_target TO PUBLIC; SELECT pg_catalog.pg_extension_config_dump('permission_target', ''); 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;$$; pg_permissions-REL_1_3/pg_permissions--1.2.sql000066400000000000000000000350231463231026600213440ustar00rootroot00000000000000-- 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' ); 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 (VALUES (TEXT 'SELECT'), ('INSERT'), ('UPDATE'), ('DELETE'), ('TRUNCATE'), ('REFERENCES'), ('TRIGGER')) 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 (VALUES (TEXT 'SELECT'), ('INSERT'), ('UPDATE'), ('DELETE'), ('TRUNCATE'), ('REFERENCES'), ('TRIGGER')) 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']::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;$$; pg_permissions-REL_1_3/pg_permissions--1.3.sql000066400000000000000000000360231463231026600213460ustar00rootroot00000000000000-- 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;$$; pg_permissions-REL_1_3/pg_permissions.control000066400000000000000000000002121463231026600216420ustar00rootroot00000000000000comment = 'view object permissions and compare them with the desired state' default_version = '1.3' relocatable = false superuser = false pg_permissions-REL_1_3/sql/000077500000000000000000000000001463231026600160035ustar00rootroot00000000000000pg_permissions-REL_1_3/sql/sample.sql000066400000000000000000000155371463231026600200200ustar00rootroot00000000000000CREATE EXTENSION pg_permissions; /* test roles (will be removed afterwards) */ CREATE ROLE users; CREATE ROLE user1 LOGIN IN ROLE users; CREATE ROLE user2 LOGIN IN ROLE users; /* database */ -- desired permissions INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('users', ARRAY['CONNECT','TEMPORARY']::perm_type[], 'DATABASE', NULL, NULL, NULL), ('user1', ARRAY['CONNECT','TEMPORARY']::perm_type[], 'DATABASE', NULL, NULL, NULL), ('user2', ARRAY['CONNECT','TEMPORARY']::perm_type[], 'DATABASE', NULL, NULL, NULL); -- this should fail INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('user2', ARRAY['CREATE']::perm_type[], 'DATABASE', 'public', NULL, NULL); -- actual permissions REVOKE ALL ON DATABASE contrib_regression FROM PUBLIC; GRANT CONNECT, TEMPORARY ON DATABASE contrib_regression TO users; GRANT CREATE ON DATABASE contrib_regression TO user2; -- too much /* schema */ -- desired permissions INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('users', ARRAY['USAGE']::perm_type[], 'SCHEMA', 'appschema', NULL, NULL), ('user1', ARRAY['USAGE','CREATE']::perm_type[], 'SCHEMA', 'appschema', NULL, NULL), ('user2', ARRAY['USAGE']::perm_type[], 'SCHEMA', 'appschema', NULL, NULL); -- this should fail INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('user2', ARRAY['CREATE']::perm_type[], 'SCHEMA', 'appschema', 'sometable', NULL); -- actual permissions CREATE SCHEMA appschema; GRANT USAGE ON SCHEMA appschema TO PUBLIC; -- missing CREATE for user1 GRANT CREATE ON SCHEMA appschema TO user2; -- too much /* table */ -- desired permissions INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('user1', ARRAY['SELECT','INSERT','UPDATE','DELETE']::perm_type[], 'TABLE', 'appschema', NULL, NULL), ('user2', ARRAY['SELECT']::perm_type[], 'TABLE', 'appschema', NULL, NULL); -- this should fail INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('user2', ARRAY['INSERT']::perm_type[], 'TABLE', 'appschema', 'apptable', 'acolumn'); -- actual permissions CREATE TABLE appschema.apptable ( id integer PRIMARY KEY, val text NOT NULL, created timestamp with time zone NOT NULL DEFAULT current_timestamp ); CREATE TABLE appschema.apptable2 ( id integer PRIMARY KEY, val text NOT NULL, created timestamp with time zone NOT NULL DEFAULT current_timestamp ); -- missing all permissions on this one GRANT SELECT, INSERT, UPDATE ON appschema.apptable TO user1; -- missing DELETE GRANT SELECT, INSERT ON appschema.apptable TO user2; -- extra privilege INSERT /* column */ -- desired permissions INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('user1', ARRAY['SELECT','INSERT','UPDATE','REFERENCES']::perm_type[], 'COLUMN', 'appschema', 'apptable2', 'val'); -- this should fail INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('user2', ARRAY['DELETE']::perm_type[], 'COLUMN', 'appschema', 'apptable2', 'val'); -- actual permissions -- missing REFERENCES for user1 on apptable2.val GRANT UPDATE (val) ON appschema.apptable2 TO user2; -- extra privilege UPDATE /* view */ -- desired permissions INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('user1', ARRAY['SELECT','INSERT','UPDATE','DELETE']::perm_type[], 'VIEW', 'appschema', 'appview', NULL), ('user2', ARRAY['SELECT']::perm_type[], 'VIEW', 'appschema', 'appview', NULL); -- actual permissions CREATE VIEW appschema.appview AS SELECT id, val FROM appschema.apptable; GRANT SELECT ON appschema.appview TO users; -- extra permission to "users" GRANT INSERT, DELETE ON appschema.appview TO user1; -- missing UPDATE /* sequence */ -- desired permissions INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('users', ARRAY['USAGE']::perm_type[], 'SEQUENCE', 'appschema', 'appseq', NULL), ('user1', ARRAY['USAGE','SELECT']::perm_type[], 'SEQUENCE', 'appschema', 'appseq', NULL), ('user2', ARRAY['USAGE']::perm_type[], 'SEQUENCE', 'appschema', 'appseq', NULL); -- actual permissions CREATE SEQUENCE appschema.appseq; GRANT USAGE ON SEQUENCE appschema.appseq TO users; -- missing SELECT for user1 GRANT UPDATE ON SEQUENCE appschema.appseq TO user2; -- extra permission UPDATE /* function */ -- desired permissions INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('user1', ARRAY['EXECUTE']::perm_type[], 'FUNCTION', 'appschema', 'appfun(integer)', NULL), ('user2', ARRAY['EXECUTE']::perm_type[], 'FUNCTION', 'appschema', 'appfun(integer)', NULL); -- this should fail INSERT INTO permission_target (role_name, permissions, object_type, schema_name, object_name, column_name) VALUES ('users', ARRAY['UPDATE']::perm_type[], 'FUNCTION', 'appschema', 'appfun(integer)', NULL); -- actual permissions CREATE FUNCTION appschema.appfun(i integer) RETURNS integer LANGUAGE sql IMMUTABLE AS 'SELECT i + 2'; -- extra permission for "users" /* report all permissions */ SELECT object_type, role_name, schema_name, object_name, column_name, permission FROM all_permissions WHERE granted AND role_name IN ('users', 'user1', 'user2') AND coalesce(schema_name, 'appschema') = 'appschema' ORDER BY object_type, role_name, schema_name, object_name, column_name, permission; /* report differences */ SELECT * FROM permission_diffs() WHERE role_name IN ('users', 'user1', 'user2') ORDER BY object_type, schema_name, object_name, column_name, role_name, permission, missing; /* fix some of the differences */ UPDATE column_permissions SET granted = TRUE WHERE role_name = 'user1' AND schema_name = 'appschema' AND object_name = 'apptable2' AND column_name = 'val' AND permission = 'REFERENCES'; UPDATE all_permissions SET granted = FALSE WHERE object_type = 'TABLE' AND role_name = 'user2' AND schema_name = 'appschema' AND object_name = 'apptable' AND permission = 'INSERT'; /* check the fixed permissions */ SELECT * FROM permission_diffs() WHERE role_name IN ('users', 'user1', 'user2') ORDER BY object_type, schema_name, object_name, column_name, role_name, permission, missing; /* clean up */ DROP FUNCTION appschema.appfun(integer); DROP VIEW appschema.appview; DROP SEQUENCE appschema.appseq; DROP TABLE appschema.apptable; DROP TABLE appschema.apptable2; DROP SCHEMA appschema; REVOKE ALL ON DATABASE contrib_regression FROM user1, user2, users; DROP ROLE user1; DROP ROLE user2; DROP ROLE users;