mirror of
https://github.com/logto-io/logto.git
synced 2024-12-16 20:26:19 -05:00
feat(schemas): init app_secrets table
This commit is contained in:
parent
e873b5d51c
commit
ca7ee8c227
5 changed files with 104 additions and 4 deletions
|
@ -42,14 +42,14 @@ const queryDatabaseManifest = async (database) => {
|
|||
`);
|
||||
|
||||
const { rows: constraints } = await pool.query(/* sql */`
|
||||
select conrelid::regclass AS table, con.*, pg_get_constraintdef(con.oid)
|
||||
select conrelid::regclass as r_table, con.*, pg_get_constraintdef(con.oid) as def
|
||||
from pg_catalog.pg_constraint con
|
||||
inner join pg_catalog.pg_class rel
|
||||
on rel.oid = con.conrelid
|
||||
inner join pg_catalog.pg_namespace nsp
|
||||
on nsp.oid = connamespace
|
||||
where nsp.nspname = 'public'
|
||||
order by conname asc;
|
||||
order by conname asc, def asc;
|
||||
`);
|
||||
|
||||
const { rows: indexes } = await pool.query(/* sql */`
|
||||
|
|
|
@ -0,0 +1,77 @@
|
|||
import { sql } from '@silverhand/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`
|
||||
-- Remove existing constraint
|
||||
alter table organization_application_relations drop constraint application_type;
|
||||
|
||||
-- Drop the function
|
||||
drop function check_application_type;
|
||||
|
||||
-- Create a new function that accepts a variadic array of application types
|
||||
create function check_application_type(
|
||||
application_id varchar(21),
|
||||
variadic target_type application_type[]
|
||||
) returns boolean as
|
||||
$$ begin
|
||||
return (select type from applications where id = application_id) = any(target_type);
|
||||
end; $$ language plpgsql set search_path = public;
|
||||
|
||||
-- Add back the constraint
|
||||
alter table organization_application_relations
|
||||
add constraint application_type
|
||||
check (check_application_type(application_id, 'MachineToMachine'));
|
||||
|
||||
-- Create the new table
|
||||
create table application_secrets (
|
||||
tenant_id varchar(21) not null
|
||||
references tenants (id) on update cascade on delete cascade,
|
||||
application_id varchar(21) not null
|
||||
references applications (id) on update cascade on delete cascade,
|
||||
/** The name of the secret. Should be unique within the application. */
|
||||
name varchar(256) not null,
|
||||
value varchar(64) not null,
|
||||
expires_at timestamptz,
|
||||
created_at timestamptz not null default now(),
|
||||
primary key (tenant_id, application_id, name),
|
||||
constraint application_type
|
||||
check (check_application_type(application_id, 'MachineToMachine', 'Traditional', 'Protected'))
|
||||
);
|
||||
`);
|
||||
await applyTableRls(pool, 'application_secrets');
|
||||
},
|
||||
down: async (pool) => {
|
||||
await dropTableRls(pool, 'application_secrets');
|
||||
await pool.query(sql`
|
||||
-- Remove the table
|
||||
drop table application_secrets;
|
||||
|
||||
-- Remove the constraint
|
||||
alter table organization_application_relations drop constraint application_type;
|
||||
|
||||
-- Drop the function
|
||||
drop function check_application_type;
|
||||
|
||||
-- Restore the original function
|
||||
create function check_application_type(
|
||||
application_id varchar(21),
|
||||
target_type application_type
|
||||
) returns boolean as
|
||||
$$ begin
|
||||
return (select type from applications where id = application_id) = target_type;
|
||||
end; $$ language plpgsql set search_path = public;
|
||||
|
||||
-- Add back the constraint
|
||||
alter table organization_application_relations
|
||||
add constraint application_type
|
||||
check (check_application_type(application_id, 'MachineToMachine'));
|
||||
`);
|
||||
},
|
||||
};
|
||||
|
||||
export default alteration;
|
|
@ -9,3 +9,6 @@
|
|||
* If we use `/default`, the URL will look ugly; thus we keep the old fashion `/console`.
|
||||
*/
|
||||
export const ossConsolePath = '/console';
|
||||
|
||||
/** The prefix for keys and values that need to be explicitly marked as internal. */
|
||||
export const internalPrefix = '#internal:';
|
||||
|
|
17
packages/schemas/tables/application_secrets.sql
Normal file
17
packages/schemas/tables/application_secrets.sql
Normal file
|
@ -0,0 +1,17 @@
|
|||
/* init_order = 2 */
|
||||
|
||||
/** Application secrets for the `client_credentials` grant type and other confidential client use cases. Note that these secrets replace the `secret` column in the `applications` table, while the `secret` column is still used for the internal validation as `oidc-provider` does not support multiple secrets per client. */
|
||||
create table application_secrets (
|
||||
tenant_id varchar(21) not null
|
||||
references tenants (id) on update cascade on delete cascade,
|
||||
application_id varchar(21) not null
|
||||
references applications (id) on update cascade on delete cascade,
|
||||
/** The name of the secret. Should be unique within the application. */
|
||||
name varchar(256) not null,
|
||||
value varchar(64) not null,
|
||||
created_at timestamptz not null default now(),
|
||||
expires_at timestamptz,
|
||||
primary key (tenant_id, application_id, name),
|
||||
constraint application_type
|
||||
check (check_application_type(application_id, 'MachineToMachine', 'Traditional', 'Protected'))
|
||||
);
|
|
@ -34,7 +34,10 @@ create unique index applications__protected_app_metadata_custom_domain
|
|||
(protected_app_metadata->'customDomains'->0->>'domain')
|
||||
);
|
||||
|
||||
create function check_application_type(application_id varchar(21), target_type application_type) returns boolean as
|
||||
create function check_application_type(
|
||||
application_id varchar(21),
|
||||
variadic target_type application_type[]
|
||||
) returns boolean as
|
||||
$$ begin
|
||||
return (select type from applications where id = application_id) = target_type;
|
||||
return (select type from applications where id = application_id) = any(target_type);
|
||||
end; $$ language plpgsql set search_path = public;
|
||||
|
|
Loading…
Reference in a new issue