From 0ebaec520edb72461a79924c708f3b1cbce491ab Mon Sep 17 00:00:00 2001 From: Darcy Ye Date: Tue, 23 May 2023 13:51:00 +0800 Subject: [PATCH] feat(schemas): update tenants table schema (#3860) --- ...d-name-tag-created-at-for-tenants-table.ts | 45 +++++++++++++++++++ packages/schemas/src/models/tenants.ts | 5 +++ packages/schemas/src/seeds/tenant.ts | 7 ++- packages/schemas/src/types/tenant.ts | 6 +++ packages/schemas/tables/_after_all.sql | 6 +++ packages/schemas/tables/_functions.sql | 6 +++ 6 files changed, 74 insertions(+), 1 deletion(-) create mode 100644 packages/schemas/alterations/next-1684382842-add-name-tag-created-at-for-tenants-table.ts diff --git a/packages/schemas/alterations/next-1684382842-add-name-tag-created-at-for-tenants-table.ts b/packages/schemas/alterations/next-1684382842-add-name-tag-created-at-for-tenants-table.ts new file mode 100644 index 000000000..1b8284ccf --- /dev/null +++ b/packages/schemas/alterations/next-1684382842-add-name-tag-created-at-for-tenants-table.ts @@ -0,0 +1,45 @@ +import { sql } from 'slonik'; + +import type { AlterationScript } from '../lib/types/alteration.js'; + +const alteration: AlterationScript = { + up: async (pool) => { + // Add new tenant columns for name, tag, and created_at. + await pool.query(sql` + alter table tenants add column name varchar(128); + alter table tenants add column tag varchar(64) not null default 'development'; + alter table tenants add column created_at timestamptz not null default(now()); + `); + // Manually set the name for existing tenants since the trigger is for new tenants only. + await pool.query(sql` + update tenants set name = concat('tenant_', id); + `); + await pool.query(sql` + alter table tenants alter column name set not null; + `); + // Create a trigger to set the tenant name since column reference is not available as default value. + await pool.query(sql` + create function set_tenant_name() returns trigger as + $$ begin + new.name := concat('tenant_', new.id); + return new; + end; $$ language plpgsql; + `); + await pool.query(sql` + create trigger set_tenant_name_trigger + before insert on tenants + for each row when (new.name is null) + execute procedure set_tenant_name(); + `); + }, + down: async (pool) => { + await pool.query(sql` + drop trigger set_tenant_name_trigger on tenants; + drop function set_tenant_name; + alter table tenants drop column name; + alter table tenants drop column tag; + alter table tenants drop column created_at; + `); + }, +}; +export default alteration; diff --git a/packages/schemas/src/models/tenants.ts b/packages/schemas/src/models/tenants.ts index e2bd0fd35..8d8a61bf9 100644 --- a/packages/schemas/src/models/tenants.ts +++ b/packages/schemas/src/models/tenants.ts @@ -1,11 +1,16 @@ import { createModel } from '@withtyped/server'; +import { TenantTag } from '../index.js'; + export const Tenants = createModel(/* sql */ ` /* init_order = 0 */ create table tenants ( id varchar(21) not null, db_user varchar(128), db_user_password varchar(128), + name varchar(128) not null, + tag varchar(64) not null default '${TenantTag.Development}', + created_at timestamptz not null default(now()), primary key (id), constraint tenants__db_user unique (db_user) diff --git a/packages/schemas/src/seeds/tenant.ts b/packages/schemas/src/seeds/tenant.ts index 60aaa9493..85847fee5 100644 --- a/packages/schemas/src/seeds/tenant.ts +++ b/packages/schemas/src/seeds/tenant.ts @@ -4,4 +4,9 @@ import type { Tenants } from '../models/tenants.js'; export const defaultTenantId = 'default'; export const adminTenantId = 'admin'; -export type TenantModel = InferModelType; + +/** + * `createModel` from @withtyped/server can not properly infer the model + * type, manually define it here for now. + */ +export type TenantModel = Pick, 'id' | 'dbUser' | 'dbUserPassword'>; diff --git a/packages/schemas/src/types/tenant.ts b/packages/schemas/src/types/tenant.ts index 570c9647c..7e6bd4172 100644 --- a/packages/schemas/src/types/tenant.ts +++ b/packages/schemas/src/types/tenant.ts @@ -1,3 +1,9 @@ +export enum TenantTag { + Development = 'development', + Staging = 'staging', + Production = 'production', +} + export type TenantInfo = { id: string; indicator: string; diff --git a/packages/schemas/tables/_after_all.sql b/packages/schemas/tables/_after_all.sql index 8a3d9b0e4..60a06ad28 100644 --- a/packages/schemas/tables/_after_all.sql +++ b/packages/schemas/tables/_after_all.sql @@ -1,5 +1,11 @@ /* This SQL will run after all other queries. */ +---- Create trigger to set tenant name ---- +create trigger set_tenant_name_trigger +before insert on tenants +for each row when (new.name is null) +execute procedure set_tenant_name(); + ---- Grant CRUD access to the group ---- grant select, insert, update, delete on all tables diff --git a/packages/schemas/tables/_functions.sql b/packages/schemas/tables/_functions.sql index ccb7a9ef9..9bb851e4e 100644 --- a/packages/schemas/tables/_functions.sql +++ b/packages/schemas/tables/_functions.sql @@ -13,4 +13,10 @@ $$ begin return new; end; $$ language plpgsql; +create function set_tenant_name() returns trigger as +$$ begin + new.name := concat('tenant_', new.id); + return new; +end; $$ language plpgsql; + /* no_after_each */