From 578a04622edd63997e9524d6faa8bc90a9e9bc6f Mon Sep 17 00:00:00 2001 From: mgbiotech <84165050+mgbiotech@users.noreply.github.com> Date: Fri, 14 May 2021 12:53:51 +1000 Subject: [PATCH 1/8] Include VIEWS in privileges (aka role, permission) Currently only table privileges are handled --- schemainspect/pg/sql/privileges.sql | 26 ++++++++++++++------------ 1 file changed, 14 insertions(+), 12 deletions(-) diff --git a/schemainspect/pg/sql/privileges.sql b/schemainspect/pg/sql/privileges.sql index f2198e0..398b044 100644 --- a/schemainspect/pg/sql/privileges.sql +++ b/schemainspect/pg/sql/privileges.sql @@ -1,16 +1,18 @@ select - table_schema as schema, - table_name as name, - 'table' as object_type, - grantee as user, - privilege_type as privilege -from information_schema.role_table_grants -where grantee != ( - select tableowner - from pg_tables - where schemaname = table_schema - and tablename = table_name -) + table_schema as schema, + table_name as name, + 'table' as object_type, + grantee as "user", + privilege_type as privilege +from + information_schema.role_table_grants r + left join pg_tables t + on t.schemaname = r.table_schema and t.tablename = r.table_name + left join pg_views v + on v.schemaname = r.table_schema and v.viewname = r.table_name +where + r.grantee is distinct from t.tableowner + and r.grantee is distinct from v.viewowner -- SKIP_INTERNAL and table_schema not in ('pg_internal', 'pg_catalog', 'information_schema', 'pg_toast') -- SKIP_INTERNAL and table_schema not like 'pg_temp_%' and table_schema not like 'pg_toast_temp_%' order by schema, name, user; From bccde5d643850f2d8e0e3e3fbc274c172532cc77 Mon Sep 17 00:00:00 2001 From: mgbiotech <84165050+mgbiotech@users.noreply.github.com> Date: Fri, 14 May 2021 13:14:40 +1000 Subject: [PATCH 2/8] Update privileges.sql --- schemainspect/pg/sql/privileges.sql | 5 +++-- 1 file changed, 3 insertions(+), 2 deletions(-) diff --git a/schemainspect/pg/sql/privileges.sql b/schemainspect/pg/sql/privileges.sql index 398b044..9e52844 100644 --- a/schemainspect/pg/sql/privileges.sql +++ b/schemainspect/pg/sql/privileges.sql @@ -7,12 +7,13 @@ select from information_schema.role_table_grants r left join pg_tables t - on t.schemaname = r.table_schema and t.tablename = r.table_name + on t.schemaname = r.table_schema and t.tablename = r.table_name left join pg_views v - on v.schemaname = r.table_schema and v.viewname = r.table_name + on v.schemaname = r.table_schema and v.viewname = r.table_name where r.grantee is distinct from t.tableowner and r.grantee is distinct from v.viewowner -- SKIP_INTERNAL and table_schema not in ('pg_internal', 'pg_catalog', 'information_schema', 'pg_toast') -- SKIP_INTERNAL and table_schema not like 'pg_temp_%' and table_schema not like 'pg_toast_temp_%' order by schema, name, user; + From e32ab287b8caeb17fa83e5afbb6ea60efbd5148c Mon Sep 17 00:00:00 2001 From: mgbiotech <84165050+mgbiotech@users.noreply.github.com> Date: Fri, 14 May 2021 19:02:06 +1000 Subject: [PATCH 3/8] Also include SEQUENCE & COLUMN privileges --- schemainspect/pg/sql/privileges.sql | 40 +++++++++++++++++------------ 1 file changed, 24 insertions(+), 16 deletions(-) diff --git a/schemainspect/pg/sql/privileges.sql b/schemainspect/pg/sql/privileges.sql index 9e52844..6fcb3d6 100644 --- a/schemainspect/pg/sql/privileges.sql +++ b/schemainspect/pg/sql/privileges.sql @@ -1,19 +1,27 @@ select - table_schema as schema, - table_name as name, - 'table' as object_type, - grantee as "user", - privilege_type as privilege + n.nspname as schema, + c.relname as name, + case + when c.relkind in ('r', 'v', 'm', 'f', 'p') then 'table' + when c.relkind = 'S' then 'sequence' + else null end as object_type, + pg_get_userbyid(acl.grantee) as "user", + acl.privilege from - information_schema.role_table_grants r - left join pg_tables t - on t.schemaname = r.table_schema and t.tablename = r.table_name - left join pg_views v - on v.schemaname = r.table_schema and v.viewname = r.table_name + pg_catalog.pg_class c + join pg_catalog.pg_namespace n + on n.oid = c.relnamespace, + lateral (select aclx.*, privilege_type as privilege + from aclexplode(c.relacl) aclx + union + select aclx.*, privilege_type || '(' || a.attname || ')' as privilege + from + pg_catalog.pg_attribute a + cross join aclexplode(a.attacl) aclx + where attrelid = c.oid and not attisdropped and attacl is not null ) acl where - r.grantee is distinct from t.tableowner - and r.grantee is distinct from v.viewowner --- SKIP_INTERNAL and table_schema not in ('pg_internal', 'pg_catalog', 'information_schema', 'pg_toast') --- SKIP_INTERNAL and table_schema not like 'pg_temp_%' and table_schema not like 'pg_toast_temp_%' -order by schema, name, user; - + acl.grantee != acl.grantor + and c.relkind in ('r', 'v', 'm', 'S', 'f', 'p') +-- SKIP_INTERNAL and nspname not in ('pg_internal', 'pg_catalog', 'information_schema', 'pg_toast') +-- SKIP_INTERNAL and nspname not like 'pg_temp_%' and nspname not like 'pg_toast_temp_%' +order by schema, name, "user"; From 8816e8c3087ec8b34f1783880c648c6b8049bade Mon Sep 17 00:00:00 2001 From: mgbiotech <84165050+mgbiotech@users.noreply.github.com> Date: Fri, 14 May 2021 20:09:00 +1000 Subject: [PATCH 4/8] Add support for function priveleges --- schemainspect/pg/sql/privileges.sql | 17 +++++++++++++++-- 1 file changed, 15 insertions(+), 2 deletions(-) diff --git a/schemainspect/pg/sql/privileges.sql b/schemainspect/pg/sql/privileges.sql index 6fcb3d6..3cdfd51 100644 --- a/schemainspect/pg/sql/privileges.sql +++ b/schemainspect/pg/sql/privileges.sql @@ -22,6 +22,19 @@ from where acl.grantee != acl.grantor and c.relkind in ('r', 'v', 'm', 'S', 'f', 'p') --- SKIP_INTERNAL and nspname not in ('pg_internal', 'pg_catalog', 'information_schema', 'pg_toast') --- SKIP_INTERNAL and nspname not like 'pg_temp_%' and nspname not like 'pg_toast_temp_%' +-- SKIP_INTERNAL and nspname not in ('pg_internal', 'pg_catalog', 'information_schema', 'pg_toast') +-- SKIP_INTERNAL and nspname not like 'pg_temp_%' and nspname not like 'pg_toast_temp_%' +union +select + routine_schema as schema, + routine_name as name, + 'function' as object_type, + grantee as "user", + privilege_type as privilege +from information_schema.role_routine_grants +where + grantor != grantee + and grantee != 'PUBLIC' +-- SKIP_INTERNAL and routine_schema not in ('pg_internal', 'pg_catalog', 'information_schema', 'pg_toast') +-- SKIP_INTERNAL and routine_schema not like 'pg_temp_%' and routine_schema not like 'pg_toast_temp_%' order by schema, name, "user"; From e6ba49ca8a3065402b9874e1c490461a895f3ab0 Mon Sep 17 00:00:00 2001 From: biodevc <84165050+biodevc@users.noreply.github.com> Date: Thu, 28 Oct 2021 14:37:35 +1100 Subject: [PATCH 5/8] Add support for schema priveleges As per @jld3103 --- schemainspect/pg/sql/privileges.sql | 22 ++++++++++++++++++++++ 1 file changed, 22 insertions(+) diff --git a/schemainspect/pg/sql/privileges.sql b/schemainspect/pg/sql/privileges.sql index 3cdfd51..060e0cf 100644 --- a/schemainspect/pg/sql/privileges.sql +++ b/schemainspect/pg/sql/privileges.sql @@ -37,4 +37,26 @@ where and grantee != 'PUBLIC' -- SKIP_INTERNAL and routine_schema not in ('pg_internal', 'pg_catalog', 'information_schema', 'pg_toast') -- SKIP_INTERNAL and routine_schema not like 'pg_temp_%' and routine_schema not like 'pg_toast_temp_%' +union +select + '' as schema, + n.nspname as name, + 'schema' as object_type, + pg_get_userbyid(acl.grantee) as "user", + privilege +from pg_catalog.pg_namespace n, + lateral (select aclx.*, privilege_type as privilege + from aclexplode(n.nspacl) aclx + union + select aclx.*, privilege_type || '(' || a.attname || ')' as privilege + from + pg_catalog.pg_attribute a + cross join aclexplode(a.attacl) aclx + where attrelid = n.oid and not attisdropped and attacl is not null ) acl +where + privilege != 'CREATE' + and acl.grantor != acl.grantee + and acl.grantee != 0 +-- SKIP_INTERNAL and n.nspname not in ('pg_internal', 'pg_catalog', 'information_schema', 'pg_toast') +-- SKIP_INTERNAL and n.nspname not like 'pg_temp_%' and n.nspname not like 'pg_toast_temp_%' order by schema, name, "user"; From d04ca6860f613f8750d9bb4c6dd86d91a7b92017 Mon Sep 17 00:00:00 2001 From: biodevc <84165050+biodevc@users.noreply.github.com> Date: Thu, 28 Oct 2021 14:39:04 +1100 Subject: [PATCH 6/8] Add support for schema privileges As per @jld3103 --- schemainspect/inspected.py | 2 ++ 1 file changed, 2 insertions(+) diff --git a/schemainspect/inspected.py b/schemainspect/inspected.py index 8ee185b..64e554e 100644 --- a/schemainspect/inspected.py +++ b/schemainspect/inspected.py @@ -6,6 +6,8 @@ class Inspected(AutoRepr): @property def quoted_full_name(self): + if self.schema == '': + return quoted_identifier(self.name) return "{}.{}".format( quoted_identifier(self.schema), quoted_identifier(self.name) ) From e01a4eed2415df1beba72502fb374b571c7ff05f Mon Sep 17 00:00:00 2001 From: biodevc <84165050+biodevc@users.noreply.github.com> Date: Thu, 23 Jun 2022 10:15:25 +1000 Subject: [PATCH 7/8] Update privileges.sql --- schemainspect/pg/sql/privileges.sql | 1 + 1 file changed, 1 insertion(+) diff --git a/schemainspect/pg/sql/privileges.sql b/schemainspect/pg/sql/privileges.sql index 060e0cf..7d06c34 100644 --- a/schemainspect/pg/sql/privileges.sql +++ b/schemainspect/pg/sql/privileges.sql @@ -21,6 +21,7 @@ from where attrelid = c.oid and not attisdropped and attacl is not null ) acl where acl.grantee != acl.grantor + and acl.grantee != 0 and c.relkind in ('r', 'v', 'm', 'S', 'f', 'p') -- SKIP_INTERNAL and nspname not in ('pg_internal', 'pg_catalog', 'information_schema', 'pg_toast') -- SKIP_INTERNAL and nspname not like 'pg_temp_%' and nspname not like 'pg_toast_temp_%' From 3689c453607271b74967ced31c0f4b8d243af3b3 Mon Sep 17 00:00:00 2001 From: biodevc <84165050+biodevc@users.noreply.github.com> Date: Thu, 23 Jun 2022 10:52:00 +1000 Subject: [PATCH 8/8] Update inspected.py --- schemainspect/inspected.py | 2 ++ 1 file changed, 2 insertions(+) diff --git a/schemainspect/inspected.py b/schemainspect/inspected.py index 8a1eb5b..24d18aa 100644 --- a/schemainspect/inspected.py +++ b/schemainspect/inspected.py @@ -6,6 +6,8 @@ class Inspected(AutoRepr): @property def quoted_full_name(self): + if self.schema == "": + return quoted_identifier(self.name) return quoted_identifier(self.name, schema=self.schema) @property