-
Notifications
You must be signed in to change notification settings - Fork 16
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Match literal underscore in LIKE pattern "pg\_%"
`_` matches single character in LIKE pattern matching, so a pattern `LIKE 'pg_%'` would match anything that starts with `pg` and is at least 3 characters long, like 'pg1'. To correct matching pattern and only match `pg_%` we need to escape literal underscore `pg\_%`
- Loading branch information
Dražen Odobašić
committed
Nov 26, 2024
1 parent
f4b7c18
commit 7190951
Showing
4 changed files
with
146 additions
and
9 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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; |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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 |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters