Skip to content

Instantly share code, notes, and snippets.

@nickreese
Last active April 6, 2023 17:55
Show Gist options
  • Star 0 You must be signed in to star a gist
  • Fork 0 You must be signed in to fork a gist
  • Save nickreese/36ce4012fc879171ce3c0c023ca32eb8 to your computer and use it in GitHub Desktop.
Save nickreese/36ce4012fc879171ce3c0c023ca32eb8 to your computer and use it in GitHub Desktop.
Check Postgres RLS Policies by Role Query
WITH
rls_enabled_tables AS (
SELECT nspname AS schema_name, relname AS table_name
FROM pg_class c
JOIN pg_namespace n ON n.oid = c.relnamespace
WHERE c.relkind = 'r' AND c.relrowsecurity = 't'
),
rls_policies AS (
SELECT p.polrelid, p.polname, p.polcmd, p.polroles
FROM pg_policy p
),
auth_role AS (
SELECT oid
FROM pg_roles
WHERE rolname = 'authenticated'
),
rls_policy_check AS (
SELECT
r.schema_name,
r.table_name,
p.polname,
p.polcmd,
(ARRAY[auth_role.oid] <@ p.polroles) AS is_assigned
FROM
rls_enabled_tables r
JOIN rls_policies p ON r.table_name::regclass = p.polrelid
CROSS JOIN auth_role
),
rls_policy_filtered AS (
SELECT
schema_name,
table_name,
STRING_AGG(polname, ', ') FILTER (WHERE (polcmd = '*' AND is_assigned)) AS all_policy,
STRING_AGG(polname, ', ') FILTER (WHERE (polcmd = 'r' AND is_assigned)) AS select_policy,
STRING_AGG(polname, ', ') FILTER (WHERE (polcmd = 'a' AND is_assigned)) AS insert_policy,
STRING_AGG(polname, ', ') FILTER (WHERE (polcmd = 'w' AND is_assigned)) AS update_policy,
STRING_AGG(polname, ', ') FILTER (WHERE (polcmd = 'd' AND is_assigned)) AS delete_policy
FROM
rls_policy_check
GROUP BY
schema_name,
table_name
)
SELECT
schema_name,
table_name,
all_policy,
select_policy,
insert_policy,
update_policy,
delete_policy
FROM
rls_policy_filtered;
Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment