Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Match literal underscore in LIKE pattern "pg\_%" #9

Merged
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
25 changes: 19 additions & 6 deletions expected/sample.out
Original file line number Diff line number Diff line change
Expand Up @@ -37,18 +37,21 @@ DETAIL: Failing row contains (8, user2, {CREATE}, SCHEMA, appschema, sometable,
CREATE SCHEMA appschema;
GRANT USAGE ON SCHEMA appschema TO PUBLIC; -- missing CREATE for user1
GRANT CREATE ON SCHEMA appschema TO user2; -- too much
CREATE SCHEMA pgabc123;
GRANT USAGE ON SCHEMA pgabc123 TO user1;
/* 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);
('user2', ARRAY['SELECT']::perm_type[], 'TABLE', 'appschema', NULL, NULL),
('user1', ARRAY['SELECT']::perm_type[], 'TABLE', 'pgabc213', 'sometable', 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).
DETAIL: Failing row contains (12, user2, {INSERT}, TABLE, appschema, apptable, acolumn).
-- actual permissions
CREATE TABLE appschema.apptable (
id integer PRIMARY KEY,
Expand All @@ -60,8 +63,14 @@ CREATE TABLE appschema.apptable2 (
val text NOT NULL,
created timestamp with time zone NOT NULL DEFAULT current_timestamp
); -- missing all permissions on this one
CREATE TABLE pgabc123.sometable (
id integer PRIMARY KEY,
val text NOT NULL,
created timestamp with time zone NOT NULL DEFAULT current_timestamp
);
GRANT SELECT, INSERT, UPDATE ON appschema.apptable TO user1; -- missing DELETE
GRANT SELECT, INSERT ON appschema.apptable TO user2; -- extra privilege INSERT
GRANT SELECT ON pgabc123.sometable TO user1;
/* column */
-- desired permissions
INSERT INTO permission_target
Expand All @@ -72,7 +81,7 @@ 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).
DETAIL: Failing row contains (14, 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
Expand Down Expand Up @@ -109,7 +118,7 @@ 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).
DETAIL: Failing row contains (22, users, {UPDATE}, FUNCTION, appschema, appfun(integer), null).
-- actual permissions
CREATE FUNCTION appschema.appfun(i integer) RETURNS integer
LANGUAGE sql IMMUTABLE AS
Expand All @@ -119,13 +128,14 @@ 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'
AND coalesce(schema_name, 'appschema') IN ('appschema', 'pgabc123')
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 | user1 | pgabc123 | sometable | | SELECT
TABLE | user2 | appschema | apptable | | SELECT
TABLE | user2 | appschema | apptable | | INSERT
VIEW | user1 | appschema | appview | | SELECT
Expand All @@ -142,6 +152,7 @@ ORDER BY object_type, role_name, schema_name, object_name, column_name, permissi
FUNCTION | user2 | appschema | appfun(integer) | | EXECUTE
FUNCTION | users | appschema | appfun(integer) | | EXECUTE
SCHEMA | user1 | appschema | | | USAGE
SCHEMA | user1 | pgabc123 | | | USAGE
SCHEMA | user2 | appschema | | | USAGE
SCHEMA | user2 | appschema | | | CREATE
SCHEMA | users | appschema | | | USAGE
Expand All @@ -152,7 +163,7 @@ ORDER BY object_type, role_name, schema_name, object_name, column_name, permissi
DATABASE | user2 | | | | TEMPORARY
DATABASE | users | | | | CONNECT
DATABASE | users | | | | TEMPORARY
(29 rows)
(31 rows)

/* report differences */
SELECT * FROM permission_diffs()
Expand Down Expand Up @@ -229,7 +240,9 @@ DROP VIEW appschema.appview;
DROP SEQUENCE appschema.appseq;
DROP TABLE appschema.apptable;
DROP TABLE appschema.apptable2;
DROP TABLE pgabc123.sometable;
DROP SCHEMA appschema;
DROP SCHEMA pgabc123;
REVOKE ALL ON DATABASE contrib_regression FROM user1, user2, users;
DROP ROLE user1;
DROP ROLE user2;
Expand Down
113 changes: 113 additions & 0 deletions pg_permissions--1.3--1.4.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,113 @@
-- 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 OR REPLACE 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;


CREATE OR REPLACE 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;


CREATE OR REPLACE 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;


CREATE OR REPLACE 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;


CREATE OR REPLACE 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;


CREATE OR REPLACE 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;
2 changes: 1 addition & 1 deletion pg_permissions.control
Original file line number Diff line number Diff line change
@@ -1,4 +1,4 @@
comment = 'view object permissions and compare them with the desired state'
default_version = '1.3'
default_version = '1.4'
relocatable = false
superuser = false
15 changes: 13 additions & 2 deletions sql/sample.sql
Original file line number Diff line number Diff line change
Expand Up @@ -40,14 +40,17 @@ VALUES ('user2', ARRAY['CREATE']::perm_type[], 'SCHEMA', 'appschema', 'sometable
CREATE SCHEMA appschema;
GRANT USAGE ON SCHEMA appschema TO PUBLIC; -- missing CREATE for user1
GRANT CREATE ON SCHEMA appschema TO user2; -- too much
CREATE SCHEMA pgabc123;
GRANT USAGE ON SCHEMA pgabc123 TO user1;

/* 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);
('user2', ARRAY['SELECT']::perm_type[], 'TABLE', 'appschema', NULL, NULL),
('user1', ARRAY['SELECT']::perm_type[], 'TABLE', 'pgabc213', 'sometable', NULL);
-- this should fail
INSERT INTO permission_target
(role_name, permissions, object_type, schema_name, object_name, column_name)
Expand All @@ -63,8 +66,14 @@ CREATE TABLE appschema.apptable2 (
val text NOT NULL,
created timestamp with time zone NOT NULL DEFAULT current_timestamp
); -- missing all permissions on this one
CREATE TABLE pgabc123.sometable (
id integer PRIMARY KEY,
val text NOT NULL,
created timestamp with time zone NOT NULL DEFAULT current_timestamp
);
GRANT SELECT, INSERT, UPDATE ON appschema.apptable TO user1; -- missing DELETE
GRANT SELECT, INSERT ON appschema.apptable TO user2; -- extra privilege INSERT
GRANT SELECT ON pgabc123.sometable TO user1;

/* column */

Expand Down Expand Up @@ -128,7 +137,7 @@ 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'
AND coalesce(schema_name, 'appschema') IN ('appschema', 'pgabc123')
ORDER BY object_type, role_name, schema_name, object_name, column_name, permission;

/* report differences */
Expand Down Expand Up @@ -168,7 +177,9 @@ DROP VIEW appschema.appview;
DROP SEQUENCE appschema.appseq;
DROP TABLE appschema.apptable;
DROP TABLE appschema.apptable2;
DROP TABLE pgabc123.sometable;
DROP SCHEMA appschema;
DROP SCHEMA pgabc123;
REVOKE ALL ON DATABASE contrib_regression FROM user1, user2, users;

DROP ROLE user1;
Expand Down