diff --git a/.scripts/compare-database.js b/.scripts/compare-database.js index 17962c5c1..6d46f56ef 100644 --- a/.scripts/compare-database.js +++ b/.scripts/compare-database.js @@ -74,6 +74,35 @@ const queryDatabaseManifest = async (database) => { `); const { rows: triggers } = await pool.query(/* sql */`select * from information_schema.triggers;`); + const { rows: policies } = await pool.query(/* sql */`select * from pg_policies order by tablename, policyname;`); + const { rows: columnGrants } = await pool.query(/* sql */` + select * from information_schema.role_column_grants + where table_schema = '${schema}' + and grantee != 'postgres' + order by grantee, table_name, column_name, privilege_type; + `); + const { rows: tableGrants } = await pool.query(/* sql */` + select * from information_schema.role_table_grants + where table_schema = '${schema}' + and grantee != 'postgres' + order by grantee, table_name, privilege_type; + `); + + // This function removes the last segment of grantee since Logto will use 'logto_tenant_fresh/alteration' for the role name. + const normalizeGrantee = ({ grantee, ...rest }) => { + if (grantee.startsWith('logto_tenant_')) { + return { ...rest, grantee: 'logto_tenant' }; + } + + return { grantee, ...rest }; + }; + + // Ditto. + const normalizeRoles = ({ roles: raw, ...rest }) => { + const roles = raw.slice(1, -1).split(',').map((name) => name.startsWith('logto_tenant_') ? 'logto_tenant' : name); + + return { roles, ...rest }; + }; // Omit generated ids and values return { @@ -100,6 +129,9 @@ const queryDatabaseManifest = async (database) => { indexes, funcs, triggers: omitArray(triggers, 'trigger_catalog', 'event_object_catalog'), + policies: policies.map(normalizeRoles), + columnGrants: omitArray(columnGrants, 'table_catalog').map(normalizeGrantee), + tableGrants: omitArray(tableGrants, 'table_catalog').map(normalizeGrantee), }; }; diff --git a/packages/schemas/alterations/next-1678269972-use-restrictive-policies.ts b/packages/schemas/alterations/next-1678269972-use-restrictive-policies.ts new file mode 100644 index 000000000..9c9355ac3 --- /dev/null +++ b/packages/schemas/alterations/next-1678269972-use-restrictive-policies.ts @@ -0,0 +1,85 @@ +import type { CommonQueryMethods } from 'slonik'; +import { sql } from 'slonik'; + +import type { AlterationScript } from '../lib/types/alteration.js'; + +const tables = [ + 'applications_roles', + 'applications', + 'connectors', + 'custom_phrases', + 'logs', + 'logto_configs', + 'oidc_model_instances', + 'passcodes', + 'resources', + 'roles_scopes', + 'roles', + 'scopes', + 'sign_in_experiences', + 'users_roles', + 'users', + 'verification_statuses', + 'hooks', +]; + +const getDatabaseName = async (pool: CommonQueryMethods) => { + const { currentDatabase } = await pool.one<{ currentDatabase: string }>(sql` + select current_database(); + `); + + return currentDatabase.replaceAll('-', '_'); +}; + +const alteration: AlterationScript = { + up: async (pool) => { + await Promise.all( + tables.map(async (tableRaw) => { + const table = sql.identifier([tableRaw]); + const tenantIdPolicy = sql.identifier([`${tableRaw}_tenant_id`]); + const modificationPolicy = sql.identifier([`${tableRaw}_modification`]); + + await pool.query(sql` + drop policy ${tenantIdPolicy} on ${table}; + create policy ${tenantIdPolicy} on ${table} + as restrictive + using (tenant_id = (select id from tenants where db_user = current_user)); + create policy ${modificationPolicy} on ${table} + using (true); + `); + }) + ); + await pool.query(sql` + drop policy tenants_tenant_id on tenants; + create policy tenants_tenant_id on tenants + using (db_user = current_user); + `); + }, + down: async (pool) => { + const role = sql.identifier([`logto_tenant_${await getDatabaseName(pool)}`]); + + await Promise.all( + tables.map(async (tableRaw) => { + const table = sql.identifier([tableRaw]); + const tenantIdPolicy = sql.identifier([`${tableRaw}_tenant_id`]); + const modificationPolicy = sql.identifier([`${tableRaw}_modification`]); + + await pool.query(sql` + drop policy ${tenantIdPolicy} on ${table}; + drop policy ${modificationPolicy} on ${table}; + create policy ${tenantIdPolicy} on ${table} + to ${role} + using (tenant_id = (select id from tenants where db_user = current_user)); + `); + }) + ); + await pool.query(sql` + drop policy tenants_tenant_id on tenants; + create policy tenants_tenant_id on tenants + to ${role} + using (db_user = current_user); + `); + }, +}; + +export default alteration; diff --git a/packages/schemas/tables/_after_all.sql b/packages/schemas/tables/_after_all.sql index e9571bd7a..6f44eef95 100644 --- a/packages/schemas/tables/_after_all.sql +++ b/packages/schemas/tables/_after_all.sql @@ -11,7 +11,7 @@ revoke all privileges on table tenants from logto_tenant_${database}; -/* Allow limited select to perform RLS query in `after_each` (using select ... from tenants ...) */ +/* Allow limited select to perform the RLS policy query in `after_each` (using select ... from tenants ...) */ grant select (id, db_user) on table tenants to logto_tenant_${database}; @@ -20,7 +20,6 @@ alter table tenants enable row level security; /* Create RLS policy to minimize the privilege */ create policy tenants_tenant_id on tenants - to logto_tenant_${database} using (db_user = current_user); -- End -- diff --git a/packages/schemas/tables/_after_each.sql b/packages/schemas/tables/_after_each.sql index e66342153..a8e44614b 100644 --- a/packages/schemas/tables/_after_each.sql +++ b/packages/schemas/tables/_after_each.sql @@ -6,5 +6,8 @@ create trigger set_tenant_id before insert on ${name} alter table ${name} enable row level security; create policy ${name}_tenant_id on ${name} - to logto_tenant_${database} + as restrictive using (tenant_id = (select id from tenants where db_user = current_user)); + +create policy ${name}_modification on ${name} + using (true);