diff --git a/.scripts/compare-database.js b/.scripts/compare-database.js index f582e96f2..61a146530 100644 --- a/.scripts/compare-database.js +++ b/.scripts/compare-database.js @@ -46,7 +46,7 @@ const queryDatabaseManifest = async (database) => { select * from pg_indexes where schemaname='${schema}' - order by tablename, indexname asc; + order by indexname asc; `); // Omit generated ids and values diff --git a/packages/cli/src/commands/database/seed/index.ts b/packages/cli/src/commands/database/seed/index.ts index 35243adfe..43a6da081 100644 --- a/packages/cli/src/commands/database/seed/index.ts +++ b/packages/cli/src/commands/database/seed/index.ts @@ -12,6 +12,7 @@ import { defaultRole, managementResourceScope, defaultRoleScopeRelation, + defaultTenant, } from '@logto/schemas'; import { Hooks, Tenants } from '@logto/schemas/models'; import chalk from 'chalk'; @@ -69,8 +70,6 @@ const createTables = async (connection: DatabaseTransactionConnection) => { ]) ); - console.log(Tenants.raw, getExplicitOrder(Tenants.raw)); - const allQueries: Array<[string, string]> = [ [Hooks.tableName, Hooks.raw], [Tenants.tableName, Tenants.raw], @@ -85,6 +84,8 @@ const createTables = async (connection: DatabaseTransactionConnection) => { }; const seedTables = async (connection: DatabaseTransactionConnection, latestTimestamp: number) => { + await connection.query(insertInto(defaultTenant, 'tenants')); + await Promise.all([ connection.query(insertInto(managementResource, 'resources')), connection.query(insertInto(managementResourceScope, 'scopes')), @@ -161,7 +162,6 @@ export const seedByPool = async (pool: DatabasePool, type: SeedChoice) => { ); } - await createTables(connection); await oraPromise(createTables(connection), { text: 'Create tables', prefixText: chalk.blue('[info]'), diff --git a/packages/schemas/alterations/next-1674032095-dedup-resources-constraint.ts b/packages/schemas/alterations/next-1674032095-dedup-resources-constraint.ts new file mode 100644 index 000000000..53083993f --- /dev/null +++ b/packages/schemas/alterations/next-1674032095-dedup-resources-constraint.ts @@ -0,0 +1,21 @@ +import { sql } from 'slonik'; + +import type { AlterationScript } from '../lib/types/alteration.js'; + +/** Drop `resources_indicator_key` unique constraint since it's duplicated with the unique index. */ +const alteration: AlterationScript = { + up: async (pool) => { + await pool.query(sql` + alter table resources + drop constraint resources_indicator_key; + `); + }, + down: async (pool) => { + await pool.query(sql` + alter table resources + add constraint resources_indicator_key unique (indicator); + `); + }, +}; + +export default alteration; diff --git a/packages/schemas/alterations/next-1674032096-oidc-model-pkey.ts b/packages/schemas/alterations/next-1674032096-oidc-model-pkey.ts new file mode 100644 index 000000000..582b52a63 --- /dev/null +++ b/packages/schemas/alterations/next-1674032096-oidc-model-pkey.ts @@ -0,0 +1,28 @@ +import { sql } from 'slonik'; + +import type { AlterationScript } from '../lib/types/alteration.js'; + +const alteration: AlterationScript = { + up: async (pool) => { + await pool.query(sql` + alter table oidc_model_instances + drop constraint oidc_model_instances_pkey, + add primary key (id); + `); + + await pool.query(sql` + create index oidc_model_instances__model_name_id + on oidc_model_instances (model_name, id); + `); + }, + down: async (pool) => { + await pool.query(sql`drop index oidc_model_instances__model_name_id;`); + await pool.query(sql` + alter table oidc_model_instances + drop constraint oidc_model_instances_pkey, + add primary key (model_name, id); + `); + }, +}; + +export default alteration; diff --git a/packages/schemas/alterations/next-1674032097-tenant-table.ts b/packages/schemas/alterations/next-1674032097-tenant-table.ts new file mode 100644 index 000000000..184afe09e --- /dev/null +++ b/packages/schemas/alterations/next-1674032097-tenant-table.ts @@ -0,0 +1,28 @@ +import { sql } from 'slonik'; + +import type { AlterationScript } from '../lib/types/alteration.js'; + +const defaultTenantId = 'default'; +const getId = (value: string) => sql.identifier([value]); + +const alteration: AlterationScript = { + up: async (pool) => { + await pool.query(sql` + create table tenants ( + id varchar(21) not null, + db_user_password varchar(128), + primary key (id) + ); + `); + + await pool.query(sql` + insert into tenants (${getId('id')}, ${getId('db_user_password')}) + values (${defaultTenantId}, null); + `); + }, + down: async (pool) => { + await pool.query(sql`drop table tenants;`); + }, +}; + +export default alteration; diff --git a/packages/schemas/alterations/next-1674032098-add-id-column.ts b/packages/schemas/alterations/next-1674032098-add-id-column.ts new file mode 100644 index 000000000..e5bfded99 --- /dev/null +++ b/packages/schemas/alterations/next-1674032098-add-id-column.ts @@ -0,0 +1,134 @@ +import { sql } from 'slonik'; + +import type { AlterationScript } from '../lib/types/alteration.js'; + +// https://github.com/viascom/nanoid-postgres/blob/main/nanoid.sql +// Removed `_-` from the default alphabet to match our JS ID generator. +const createNanoId = sql` + /* + * Copyright 2022 Viascom Ltd liab. Co + * + * Licensed to the Apache Software Foundation (ASF) under one + * or more contributor license agreements. See the NOTICE file + * distributed with this work for additional information + * regarding copyright ownership. The ASF licenses this file + * to you under the Apache License, Version 2.0 (the + * "License"); you may not use this file except in compliance + * with the License. You may obtain a copy of the License at + * + * http://www.apache.org/licenses/LICENSE-2.0 + * + * Unless required by applicable law or agreed to in writing, + * software distributed under the License is distributed on an + * "AS IS" BASIS, WITHOUT WARRANTIES OR CONDITIONS OF ANY + * KIND, either express or implied. See the License for the + * specific language governing permissions and limitations + * under the License. + */ + + CREATE EXTENSION IF NOT EXISTS pgcrypto; + + CREATE OR REPLACE FUNCTION nanoid(size int DEFAULT 21, alphabet text DEFAULT '0123456789abcdefghijklmnopqrstuvwxyzABCDEFGHIJKLMNOPQRSTUVWXYZ') + RETURNS text + LANGUAGE plpgsql + volatile + AS + $$ + DECLARE + idBuilder text := ''; + i int := 0; + bytes bytea; + alphabetIndex int; + mask int; + step int; + BEGIN + mask := (2 << cast(floor(log(length(alphabet) - 1) / log(2)) as int)) - 1; + step := cast(ceil(1.6 * mask * size / length(alphabet)) AS int); + + while true + loop + bytes := gen_random_bytes(size); + while i < size + loop + alphabetIndex := (get_byte(bytes, i) & mask) + 1; + if alphabetIndex <= length(alphabet) then + idBuilder := idBuilder || substr(alphabet, alphabetIndex, 1); + if length(idBuilder) = size then + return idBuilder; + end if; + end if; + i = i + 1; + end loop; + + i := 0; + end loop; + END + $$; +`; + +const getId = (value: string) => sql.identifier([value]); + +type TableInfo = { + table: string; + primaryKeys: string[]; +}; + +const tablesWithId: TableInfo[] = [ + { table: 'applications_roles', primaryKeys: ['application_id', 'role_id'] }, + { table: 'custom_phrases', primaryKeys: ['language_tag'] }, + { table: 'roles_scopes', primaryKeys: ['role_id', 'scope_id'] }, + { table: 'users_roles', primaryKeys: ['user_id', 'role_id'] }, +]; + +const alteration: AlterationScript = { + up: async (pool) => { + await pool.query(createNanoId); + + // Add id column to tables + await Promise.all( + tablesWithId.map(async ({ table, primaryKeys }) => + pool.query(sql` + alter table ${getId(table)} + add column id varchar(21) not null default nanoid(), + drop constraint ${getId(table + '_pkey')}, + add primary key (id), + add constraint ${getId(table + '__' + primaryKeys.join('_'))} + unique (${sql.join( + primaryKeys.map((key) => getId(key)), + sql`, ` + )}); + `) + ) + ); + + // Nano IDs should be generated by JS to align with other tables, so we drop the default value here. + // Also usually backend server has a better specification. :-) + await Promise.all( + tablesWithId.map(async ({ table }) => + pool.query(sql` + alter table ${getId(table)} alter column id drop default; + `) + ) + ); + + await pool.query(sql`drop function nanoid;`); + }, + down: async (pool) => { + // Add id column to tables + await Promise.all( + tablesWithId.map(async ({ table, primaryKeys }) => + pool.query(sql` + alter table ${getId(table)} + drop column id, + drop constraint ${getId(table + '__' + primaryKeys.join('_'))}, + add primary key (${sql.join( + primaryKeys.map((key) => getId(key)), + sql`, ` + )}); + `) + ) + ); + }, +}; + +export default alteration; diff --git a/packages/schemas/alterations/next-1674032099-multi-tenancy.ts b/packages/schemas/alterations/next-1674032099-multi-tenancy.ts index a2e8d17f5..d48558ac8 100644 --- a/packages/schemas/alterations/next-1674032099-multi-tenancy.ts +++ b/packages/schemas/alterations/next-1674032099-multi-tenancy.ts @@ -1,4 +1,3 @@ -import { conditionalString } from '@silverhand/essentials'; import { sql } from 'slonik'; import { raw } from 'slonik-sql-tag-raw'; @@ -6,31 +5,28 @@ import type { AlterationScript } from '../lib/types/alteration.js'; const getId = (value: string) => sql.identifier([value]); const tenantId = sql.identifier(['tenant_id']); -const defaultTenantId = 'default'; -// [table name, primary key array] -type TableInfo = [string, string[]]; - -const tables: TableInfo[] = [ - ['applications', ['id']], - ['connectors', ['id']], - ['custom_phrases', ['language_tag']], - ['logs', ['id']], - ['oidc_model_instances', ['model_name', 'id']], - ['passcodes', ['id']], - ['resources', ['id']], - ['roles', ['id']], - ['roles_scopes', ['role_id', 'scope_id']], - ['scopes', ['id']], - ['settings', ['id']], - ['sign_in_experiences', ['id']], - ['users_roles', ['user_id', 'role_id']], - ['users', ['id']], +const tables: string[] = [ + 'applications_roles', + 'applications', + 'connectors', + 'custom_phrases', + 'logs', + 'oidc_model_instances', + 'passcodes', + 'resources', + 'roles_scopes', + 'roles', + 'scopes', + 'settings', + 'sign_in_experiences', + 'users_roles', + 'users', ]; type IndexInfo = { table: string; - indexes: Array<{ name?: string; type?: 'unique'; columns: string[]; strategy?: 'drop-only' }>; + indexes: Array<{ name?: string; columns: string[]; strategy?: 'drop-only' }>; }; const indexes: IndexInfo[] = [ @@ -46,6 +42,7 @@ const indexes: IndexInfo[] = [ { table: 'oidc_model_instances', indexes: [ + { columns: ['model_name', 'id'] }, { name: 'model_name_payload_user_code', columns: ['model_name', "(payload->>'userCode')"] }, { name: 'model_name_payload_uid', columns: ['model_name', "(payload->>'uid')"] }, { name: 'model_name_payload_grant_id', columns: ['model_name', "(payload->>'grantId')"] }, @@ -59,66 +56,69 @@ const indexes: IndexInfo[] = [ { columns: ['phone', 'type'] }, ], }, - { table: 'resources', indexes: [{ type: 'unique', columns: ['indicator'] }] }, - { table: 'roles', indexes: [{ type: 'unique', columns: ['name'] }] }, - { table: 'scopes', indexes: [{ type: 'unique', columns: ['resource_id', 'name'] }] }, { table: 'users', indexes: [{ columns: ['name'] }, { columns: ['created_at'], strategy: 'drop-only' }], }, ]; +type ConstraintInfo = { + table: string; + columns: string[]; + original?: 'index'; +}; + +const constraints: ConstraintInfo[] = [ + { table: 'applications_roles', columns: ['application_id', 'role_id'] }, + { table: 'custom_phrases', columns: ['language_tag'] }, + { table: 'roles_scopes', columns: ['role_id', 'scope_id'] }, + { table: 'users_roles', columns: ['user_id', 'role_id'] }, + { table: 'resources', columns: ['indicator'], original: 'index' }, + { table: 'roles', columns: ['name'], original: 'index' }, + { table: 'scopes', columns: ['resource_id', 'name'], original: 'index' }, +]; + const alteration: AlterationScript = { up: async (pool) => { - await pool.query(sql` - create table tenants ( - id varchar(21) not null, - db_user_password varchar(128), - primary key (id) - ); - `); - - await pool.query(sql` - insert into tenants (${getId('id')}, ${getId('db_user_password')}) - values (${defaultTenantId}, null); - `); - - // Update primary keys + // Add `tenant_id` column and create index accordingly await Promise.all( - tables.map(async ([tableName, primaryKeys]) => { - // Add `tenant_id` column and set existing data to a default tenant + tables.map(async (tableName) => { + // Add `tenant_id` column and set existing data to the default tenant await pool.query(sql` - alter table ${sql.identifier([tableName])} + alter table ${getId(tableName)} add column ${tenantId} varchar(21) not null default 'default' - references tenants (id) on update cascade on delete cascade, - drop constraint ${sql.identifier([tableName + '_pkey'])} cascade, - add primary key (${sql.join( - ['tenant_id', ...primaryKeys].map((key) => sql.identifier([key])), - sql`, ` - )}); + references tenants (id) on update cascade on delete cascade; `); - // Column should not have a default tenant ID, it should be always manually assigned + // Column should not have a default tenant ID, it should be always assigned manually or by a trigger await pool.query(sql` - alter table ${sql.identifier([tableName])} - alter column ${tenantId} drop default; + alter table ${getId(tableName)} + alter column ${tenantId} drop default; `); + + // Skip OIDC model instances since we always query them with a model name + if (tableName !== 'oidc_model_instances') { + // Add ID index for better RLS query performance + await pool.query(sql` + create index ${getId(`${tableName}__id`)} + on ${getId(tableName)} (${tenantId}, id); + `); + } }) ); // Update indexes await Promise.all( indexes.flatMap(({ table, indexes }) => - indexes.map(async ({ name, type, columns, strategy }) => { + indexes.map(async ({ name, columns, strategy }) => { const indexName = getId(`${table}__${name ?? columns.join('_')}`); await pool.query(sql`drop index ${indexName}`); if (strategy !== 'drop-only') { await pool.query( sql` - create ${raw(conditionalString(type))} index ${indexName} - on ${getId(table)} - ( + create index ${indexName} + on ${getId(table)} ( ${tenantId}, ${sql.join( columns.map((column) => raw(column)), @@ -131,9 +131,98 @@ const alteration: AlterationScript = { }) ) ); + + // Update constraints + await Promise.all( + constraints.map(async ({ table, columns, original }) => { + const indexName = getId(`${table}__${columns.join('_')}`); + + if (original === 'index') { + await pool.query(sql`drop index ${indexName}`); + } + + await pool.query(sql` + alter table ${getId(table)} + ${original === 'index' ? sql`` : sql`drop constraint ${indexName},`} + add constraint ${indexName} unique ( + ${tenantId}, + ${sql.join( + columns.map((column) => raw(column)), + sql`, ` + )} + ); + `); + }) + ); }, down: async (pool) => { - throw new Error('Not implemented'); + // Restore constraints + await Promise.all( + constraints.map(async ({ table, columns, original }) => { + const indexName = getId(`${table}__${columns.join('_')}`); + + await pool.query(sql` + alter table ${getId(table)} + drop constraint ${indexName}; + `); + + await (original === 'index' + ? pool.query(sql` + create unique index ${indexName} + on ${getId(table)} ( + ${sql.join( + columns.map((column) => raw(column)), + sql`, ` + )} + ) + `) + : pool.query(sql` + alter table ${getId(table)} + add constraint ${indexName} unique ( + ${sql.join( + columns.map((column) => raw(column)), + sql`, ` + )} + ); + `)); + }) + ); + + // Restore indexes + await Promise.all( + indexes.flatMap(({ table, indexes }) => + indexes.map(async ({ name, columns, strategy }) => { + const indexName = getId(`${table}__${name ?? columns.join('_')}`); + + if (strategy !== 'drop-only') { + await pool.query(sql`drop index ${indexName}`); + } + + await pool.query( + sql` + create index ${indexName} + on ${getId(table)} ( + ${sql.join( + columns.map((column) => raw(column)), + sql`, ` + )} + ); + ` + ); + }) + ) + ); + + // Drop `tenant_id` column cascade + await Promise.all( + tables.map(async (tableName) => { + // Add `tenant_id` column and set existing data to the default tenant + await pool.query(sql` + alter table ${getId(tableName)} + drop column ${tenantId} cascade; + `); + }) + ); }, }; diff --git a/packages/schemas/src/models/tenants.ts b/packages/schemas/src/models/tenants.ts index e40051f66..454680c52 100644 --- a/packages/schemas/src/models/tenants.ts +++ b/packages/schemas/src/models/tenants.ts @@ -3,8 +3,8 @@ import { createModel } from '@withtyped/server'; export const Tenants = createModel(/* sql */ ` /* init_order = 0 */ create table tenants ( - id varchar(32) not null, - db_user_password varchar(128) not null, + id varchar(21) not null, + db_user_password varchar(128), primary key (id) ); `); diff --git a/packages/schemas/src/seeds/index.ts b/packages/schemas/src/seeds/index.ts index 490bb7bd4..63017e9de 100644 --- a/packages/schemas/src/seeds/index.ts +++ b/packages/schemas/src/seeds/index.ts @@ -4,3 +4,4 @@ export * from './setting.js'; export * from './sign-in-experience.js'; export * from './roles.js'; export * from './scope.js'; +export * from './tenant.js'; diff --git a/packages/schemas/src/seeds/roles.ts b/packages/schemas/src/seeds/roles.ts index f60489c64..ed98c3153 100644 --- a/packages/schemas/src/seeds/roles.ts +++ b/packages/schemas/src/seeds/roles.ts @@ -1,3 +1,5 @@ +import { generateStandardId } from '@logto/core-kit'; + import type { CreateRole, CreateRolesScope } from '../db-entries/index.js'; import { UserRole } from '../types/index.js'; import { managementResourceScopeId } from './scope.js'; @@ -16,6 +18,7 @@ export const defaultRole: Readonly = { }; export const defaultRoleScopeRelation: Readonly = { + id: generateStandardId(), tenantId: defaultTenantId, roleId: adminConsoleAdminRoleId, scopeId: managementResourceScopeId, diff --git a/packages/schemas/src/seeds/tenant.ts b/packages/schemas/src/seeds/tenant.ts index 884073d89..bd733880d 100644 --- a/packages/schemas/src/seeds/tenant.ts +++ b/packages/schemas/src/seeds/tenant.ts @@ -1,2 +1,11 @@ +import type { InferModelType } from '@withtyped/server'; + +import type { Tenants } from '../models/tenants.js'; + export const defaultTenantId = 'default'; export const adminTenantId = 'admin'; + +export const defaultTenant: InferModelType = { + id: defaultTenantId, + dbUserPassword: null, +}; diff --git a/packages/schemas/tables/resources.sql b/packages/schemas/tables/resources.sql index 9b5a3ed9a..ea16c6300 100644 --- a/packages/schemas/tables/resources.sql +++ b/packages/schemas/tables/resources.sql @@ -1,9 +1,11 @@ +/* init_order = 1 */ + create table resources ( tenant_id varchar(21) not null references tenants (id) on update cascade on delete cascade, id varchar(21) not null, name text not null, - indicator text not null unique, /* resource indicator also used as audience */ + indicator text not null, /* resource indicator also used as audience */ access_token_ttl bigint not null default(3600), /* expiration value in seconds, default is 1h */ primary key (id), constraint resources__indicator @@ -11,4 +13,4 @@ create table resources ( ); create index resources__id - on resources (tenant_id, indicator); + on resources (tenant_id, id); diff --git a/packages/schemas/tables/scopes.sql b/packages/schemas/tables/scopes.sql index 86e8a631a..74f1d4a89 100644 --- a/packages/schemas/tables/scopes.sql +++ b/packages/schemas/tables/scopes.sql @@ -1,3 +1,5 @@ +/* init_order = 2 */ + create table scopes ( tenant_id varchar(21) not null references tenants (id) on update cascade on delete cascade, diff --git a/packages/schemas/tables/users_roles.sql b/packages/schemas/tables/users_roles.sql index 38a5f3411..be78daf0c 100644 --- a/packages/schemas/tables/users_roles.sql +++ b/packages/schemas/tables/users_roles.sql @@ -1,13 +1,14 @@ create table users_roles ( - id varchar(21) not null, tenant_id varchar(21) not null references tenants (id) on update cascade on delete cascade, + id varchar(21) not null, user_id varchar(21) not null references users (id) on update cascade on delete cascade, role_id varchar(21) not null references roles (id) on update cascade on delete cascade, primary key (id), - constraint users_roles__user_id_role_id unique (tenant_id, user_id, role_id) + constraint users_roles__user_id_role_id + unique (tenant_id, user_id, role_id) ); create index users_roles__id