From 571b53d9cce0a6860f948963c2f64331c5df84a2 Mon Sep 17 00:00:00 2001 From: Gao Sun Date: Thu, 11 Jan 2024 14:38:37 +0800 Subject: [PATCH] feat(schemas): init org invitation tables --- .github/workflows/main.yml | 2 +- .scripts/check-alterations-sequence.js | 7 +- .../next-1704934999-add-magic-links-table.ts | 37 ++++++++++ ...5001-add-organization-invitation-tables.ts | 70 +++++++++++++++++++ .../alterations/utils/1704934999-tables.ts | 49 +++++++++++++ packages/schemas/alterations/utils/README.md | 9 +++ .../src/foundations/jsonb-types/index.ts | 1 + .../foundations/jsonb-types/organizations.ts | 14 ++++ packages/schemas/tables/magic_links.sql | 23 ++++++ ...organization_invitation_role_relations.sql | 14 ++++ .../tables/organization_invitations.sql | 33 +++++++++ 11 files changed, 257 insertions(+), 2 deletions(-) create mode 100644 packages/schemas/alterations/next-1704934999-add-magic-links-table.ts create mode 100644 packages/schemas/alterations/next-1704935001-add-organization-invitation-tables.ts create mode 100644 packages/schemas/alterations/utils/1704934999-tables.ts create mode 100644 packages/schemas/alterations/utils/README.md create mode 100644 packages/schemas/src/foundations/jsonb-types/organizations.ts create mode 100644 packages/schemas/tables/magic_links.sql create mode 100644 packages/schemas/tables/organization_invitation_role_relations.sql create mode 100644 packages/schemas/tables/organization_invitations.sql diff --git a/.github/workflows/main.yml b/.github/workflows/main.yml index 535e23c2d..c936f6232 100644 --- a/.github/workflows/main.yml +++ b/.github/workflows/main.yml @@ -193,6 +193,6 @@ jobs: run: node .scripts/compare-database.js fresh old # ** End ** - - name: Check alteration databases + - name: Check alteration sequence working-directory: ./fresh run: node .scripts/check-alterations-sequence.js diff --git a/.scripts/check-alterations-sequence.js b/.scripts/check-alterations-sequence.js index 080254fd1..a0b81dac9 100644 --- a/.scripts/check-alterations-sequence.js +++ b/.scripts/check-alterations-sequence.js @@ -19,7 +19,10 @@ const diffFiles = execSync("git diff HEAD~1 HEAD --name-only --diff-filter=ACR", }); const committedAlterations = diffFiles .split("\n") - .filter((filename) => filename.startsWith(alterationFilePrefix)) + .filter((filename) => + filename.startsWith(alterationFilePrefix) && + !filename.slice(alterationFilePrefix.length).includes("/") + ) .map((filename) => filename.replace(alterationFilePrefix, "").replace(".ts", "") ); @@ -32,4 +35,6 @@ for (const alteration of committedAlterations) { `Wrong alteration sequence for committed file: ${alteration}\nAll timestamps of committed alteration files should be greater than the biggest one in the base branch.` ); } + + console.log(`✅ ${alteration}`); } diff --git a/packages/schemas/alterations/next-1704934999-add-magic-links-table.ts b/packages/schemas/alterations/next-1704934999-add-magic-links-table.ts new file mode 100644 index 000000000..38c029877 --- /dev/null +++ b/packages/schemas/alterations/next-1704934999-add-magic-links-table.ts @@ -0,0 +1,37 @@ +import { sql } from 'slonik'; + +import type { AlterationScript } from '../lib/types/alteration.js'; + +import { applyTableRls, dropTableRls } from './utils/1704934999-tables.js'; + +const alteration: AlterationScript = { + up: async (pool) => { + await pool.query(sql` + create table magic_links ( + tenant_id varchar(21) not null + references tenants (id) on update cascade on delete cascade, + /** The unique identifier of the link. */ + id varchar(21) not null, + /** The token that can be used to verify the link. */ + token varchar(32) not null, + /** The time when the link was created. */ + created_at timestamptz not null default (now()), + /** The time when the link was consumed. */ + consumed_at timestamptz, + primary key (id) + ); + + create index magic_links__token + on magic_links (tenant_id, token); + `); + await applyTableRls(pool, 'magic_links'); + }, + down: async (pool) => { + await dropTableRls(pool, 'magic_links'); + await pool.query(sql` + drop table magic_links; + `); + }, +}; + +export default alteration; diff --git a/packages/schemas/alterations/next-1704935001-add-organization-invitation-tables.ts b/packages/schemas/alterations/next-1704935001-add-organization-invitation-tables.ts new file mode 100644 index 000000000..318251053 --- /dev/null +++ b/packages/schemas/alterations/next-1704935001-add-organization-invitation-tables.ts @@ -0,0 +1,70 @@ +import { sql } from 'slonik'; + +import type { AlterationScript } from '../lib/types/alteration.js'; + +import { applyTableRls, dropTableRls } from './utils/1704934999-tables.js'; + +const alteration: AlterationScript = { + up: async (pool) => { + await pool.query(sql` + create table organization_invitations ( + tenant_id varchar(21) not null + references tenants (id) on update cascade on delete cascade, + /** The unique identifier of the invitation. */ + id varchar(21) not null, + /** The user ID who sent the invitation. */ + inviter_id varchar(21) not null, + /** The email address or other identifier of the invitee. */ + invitee varchar(256) not null, + /** The user ID of who accepted the invitation. */ + accepted_user_id varchar(21) + references users (id) on update cascade on delete cascade, + /** The ID of the organization to which the invitee is invited. */ + organization_id varchar(21) not null, + /** The status of the invitation. */ + status varchar(32) /* @use OrganizationInvitationStatus */ not null, + /** The ID of the magic link that can be used to accept the invitation. */ + magic_link_id varchar(21) + references magic_links (id) on update cascade on delete cascade, + /** The time when the invitation was created. */ + created_at timestamptz not null default (now()), + /** The time when the invitation status was last updated. */ + updated_at timestamptz not null default (now()), + /** The time when the invitation expires. */ + expires_at timestamptz not null, + primary key (id), + foreign key (tenant_id, inviter_id, organization_id) + references organization_user_relations (tenant_id, user_id, organization_id) + on update cascade on delete cascade + ); + `); + await applyTableRls(pool, 'organization_invitations'); + + await pool.query(sql` + create table organization_invitation_role_relations ( + tenant_id varchar(21) not null + references tenants (id) on update cascade on delete cascade, + /** The ID of the invitation. */ + invitation_id varchar(21) not null + references organization_invitations (id) on update cascade on delete cascade, + /** The ID of the organization role. */ + organization_role_id varchar(21) not null + references organization_roles (id) on update cascade on delete cascade, + primary key (tenant_id, invitation_id, organization_role_id) + ); + `); + await applyTableRls(pool, 'organization_invitation_role_relations'); + }, + down: async (pool) => { + await dropTableRls(pool, 'organization_invitation_role_relations'); + await pool.query(sql` + drop table organization_invitation_role_relations; + `); + await dropTableRls(pool, 'organization_invitations'); + await pool.query(sql` + drop table organization_invitations; + `); + }, +}; + +export default alteration; diff --git a/packages/schemas/alterations/utils/1704934999-tables.ts b/packages/schemas/alterations/utils/1704934999-tables.ts new file mode 100644 index 000000000..df7c574de --- /dev/null +++ b/packages/schemas/alterations/utils/1704934999-tables.ts @@ -0,0 +1,49 @@ +import { type CommonQueryMethods, sql } from 'slonik'; + +const getId = (value: string) => sql.identifier([value]); + +const getDatabaseName = async (pool: CommonQueryMethods) => { + const { currentDatabase } = await pool.one<{ currentDatabase: string }>(sql` + select current_database(); + `); + + return currentDatabase.replaceAll('-', '_'); +}; + +/** + * A function to call after the table is created. It will apply the necessary row-level security + * policies and triggers to the table. + */ +export const applyTableRls = async (pool: CommonQueryMethods, tableName: string) => { + const database = await getDatabaseName(pool); + const baseRoleId = getId(`logto_tenant_${database}`); + const table = getId(tableName); + + await pool.query(sql` + create trigger set_tenant_id before insert on ${table} + for each row execute procedure set_tenant_id(); + + alter table ${table} enable row level security; + + create policy ${getId(`${tableName}_tenant_id`)} on ${table} + as restrictive + using (tenant_id = (select id from tenants where db_user = current_user)); + + create policy ${getId(`${tableName}_modification`)} on ${table} + using (true); + + grant select, insert, update, delete on ${table} to ${baseRoleId}; + `); +}; + +/** + * A function to call before the table is dropped. It will remove the row-level security policies + * and triggers from the table. + */ +export const dropTableRls = async (pool: CommonQueryMethods, tableName: string) => { + await pool.query(sql` + drop policy ${getId(`${tableName}_modification`)} on ${getId(tableName)}; + drop policy ${getId(`${tableName}_tenant_id`)} on ${getId(tableName)}; + drop trigger set_tenant_id on ${getId(tableName)}; + `); +}; diff --git a/packages/schemas/alterations/utils/README.md b/packages/schemas/alterations/utils/README.md new file mode 100644 index 000000000..527a81da5 --- /dev/null +++ b/packages/schemas/alterations/utils/README.md @@ -0,0 +1,9 @@ +# Alteration utils + +This directory contains utilities for database alteration scripts. + +Due to the nature of alteration, all utility functions should be maintained in an immutable way. This means when a function needs to be changed, a new file should be created with the following name format: + +`-.js` + +The timestamp should be in the format of epoch time in seconds. The original file should be kept for historical purposes. diff --git a/packages/schemas/src/foundations/jsonb-types/index.ts b/packages/schemas/src/foundations/jsonb-types/index.ts index f7eda8966..7494dcc63 100644 --- a/packages/schemas/src/foundations/jsonb-types/index.ts +++ b/packages/schemas/src/foundations/jsonb-types/index.ts @@ -11,6 +11,7 @@ export * from './sentinel.js'; export * from './users.js'; export * from './sso-connector.js'; export * from './applications.js'; +export * from './organizations.js'; export { configurableConnectorMetadataGuard, diff --git a/packages/schemas/src/foundations/jsonb-types/organizations.ts b/packages/schemas/src/foundations/jsonb-types/organizations.ts new file mode 100644 index 000000000..4240a4b30 --- /dev/null +++ b/packages/schemas/src/foundations/jsonb-types/organizations.ts @@ -0,0 +1,14 @@ +import { z } from 'zod'; + +/** The status of an organization invitation. */ +export enum OrganizationInvitationStatus { + /** The invitation is pending for the invitee's response. */ + Pending = 'Pending', + /** The invitation is accepted by the invitee. */ + Accepted = 'Accepted', + /** The invitation is revoked by the inviter. */ + Revoked = 'Revoked', + /** The invitation is expired, or the invitee has already joined the organization. */ + Expired = 'Expired', +} +export const organizationInvitationStatusGuard = z.nativeEnum(OrganizationInvitationStatus); diff --git a/packages/schemas/tables/magic_links.sql b/packages/schemas/tables/magic_links.sql new file mode 100644 index 000000000..5b6f66b2e --- /dev/null +++ b/packages/schemas/tables/magic_links.sql @@ -0,0 +1,23 @@ +/* init_order = 1 */ + +/** + * Link that can be used to perform certain actions by verifying the token. The expiration time + * of the link should be determined by the action it performs, thus there is no `expires_at` + * column in this table. + */ +create table magic_links ( + tenant_id varchar(21) not null + references tenants (id) on update cascade on delete cascade, + /** The unique identifier of the link. */ + id varchar(21) not null, + /** The token that can be used to verify the link. */ + token varchar(32) not null, + /** The time when the link was created. */ + created_at timestamptz not null default (now()), + /** The time when the link was consumed. */ + consumed_at timestamptz, + primary key (id) +); + +create index magic_links__token + on magic_links (tenant_id, token); diff --git a/packages/schemas/tables/organization_invitation_role_relations.sql b/packages/schemas/tables/organization_invitation_role_relations.sql new file mode 100644 index 000000000..b75c1708e --- /dev/null +++ b/packages/schemas/tables/organization_invitation_role_relations.sql @@ -0,0 +1,14 @@ +/* init_order = 4 */ + +/** The organization roles that will be assigned to a user when they accept an invitation. */ +create table organization_invitation_role_relations ( + tenant_id varchar(21) not null + references tenants (id) on update cascade on delete cascade, + /** The ID of the invitation. */ + invitation_id varchar(21) not null + references organization_invitations (id) on update cascade on delete cascade, + /** The ID of the organization role. */ + organization_role_id varchar(21) not null + references organization_roles (id) on update cascade on delete cascade, + primary key (tenant_id, invitation_id, organization_role_id) +); diff --git a/packages/schemas/tables/organization_invitations.sql b/packages/schemas/tables/organization_invitations.sql new file mode 100644 index 000000000..dec20db21 --- /dev/null +++ b/packages/schemas/tables/organization_invitations.sql @@ -0,0 +1,33 @@ +/* init_order = 3 */ + +/** The invitation entry defined in RFC 0003. It stores the invitation information for a user to join an organization. */ +create table organization_invitations ( + tenant_id varchar(21) not null + references tenants (id) on update cascade on delete cascade, + /** The unique identifier of the invitation. */ + id varchar(21) not null, + /** The user ID who sent the invitation. */ + inviter_id varchar(21) not null, + /** The email address or other identifier of the invitee. */ + invitee varchar(256) not null, + /** The user ID of who accepted the invitation. */ + accepted_user_id varchar(21) + references users (id) on update cascade on delete cascade, + /** The ID of the organization to which the invitee is invited. */ + organization_id varchar(21) not null, + /** The status of the invitation. */ + status varchar(32) /* @use OrganizationInvitationStatus */ not null, + /** The ID of the magic link that can be used to accept the invitation. */ + magic_link_id varchar(21) + references magic_links (id) on update cascade on delete cascade, + /** The time when the invitation was created. */ + created_at timestamptz not null default (now()), + /** The time when the invitation status was last updated. */ + updated_at timestamptz not null default (now()), + /** The time when the invitation expires. */ + expires_at timestamptz not null, + primary key (id), + foreign key (tenant_id, inviter_id, organization_id) + references organization_user_relations (tenant_id, user_id, organization_id) + on update cascade on delete cascade +);