mirror of
https://github.com/logto-io/logto.git
synced 2024-12-16 20:26:19 -05:00
Merge pull request #5220 from logto-io/gao-init-invitation-tables
feat(schemas): init org invitation tables
This commit is contained in:
commit
a59250ee49
9 changed files with 257 additions and 2 deletions
2
.github/workflows/main.yml
vendored
2
.github/workflows/main.yml
vendored
|
@ -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
|
||||
|
|
|
@ -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}`);
|
||||
}
|
||||
|
|
|
@ -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;
|
|
@ -0,0 +1,78 @@
|
|||
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 type organization_invitation_status as enum ('Pending', 'Accepted', 'Expired', 'Revoked');
|
||||
|
||||
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 organization_invitation_status 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
|
||||
);
|
||||
|
||||
-- Ensure there is only one pending invitation for a given invitee and organization.
|
||||
create unique index organization_invitations__invitee_organization_id
|
||||
on organization_invitations (tenant_id, invitee, organization_id)
|
||||
where status = 'Pending';
|
||||
`);
|
||||
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;
|
||||
drop type organization_invitation_status;
|
||||
`);
|
||||
},
|
||||
};
|
||||
|
||||
export default alteration;
|
49
packages/schemas/alterations/utils/1704934999-tables.ts
Normal file
49
packages/schemas/alterations/utils/1704934999-tables.ts
Normal file
|
@ -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)};
|
||||
`);
|
||||
};
|
9
packages/schemas/alterations/utils/README.md
Normal file
9
packages/schemas/alterations/utils/README.md
Normal file
|
@ -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:
|
||||
|
||||
`<timestamp>-<function-or-purpose>.js`
|
||||
|
||||
The timestamp should be in the format of epoch time in seconds. The original file should be kept for historical purposes.
|
23
packages/schemas/tables/magic_links.sql
Normal file
23
packages/schemas/tables/magic_links.sql
Normal file
|
@ -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);
|
|
@ -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)
|
||||
);
|
40
packages/schemas/tables/organization_invitations.sql
Normal file
40
packages/schemas/tables/organization_invitations.sql
Normal file
|
@ -0,0 +1,40 @@
|
|||
/* init_order = 3 */
|
||||
|
||||
create type organization_invitation_status as enum ('Pending', 'Accepted', 'Expired', 'Revoked');
|
||||
|
||||
/** 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 organization_invitation_status 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
|
||||
);
|
||||
|
||||
-- Ensure there is only one pending invitation for a given invitee and organization.
|
||||
create unique index organization_invitations__invitee_organization_id
|
||||
on organization_invitations (tenant_id, invitee, organization_id)
|
||||
where status = 'Pending';
|
Loading…
Reference in a new issue