You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.
boundary/internal/db/migrations/postgres/04_iam.up.sql

229 lines
5.5 KiB

begin;
create table iam_scope_type_enm (
string text not null primary key check(string in ('unknown', 'organization', 'project'))
);
insert into iam_scope_type_enm (string)
values
('unknown'),
('organization'),
('project');
create table iam_scope (
public_id wt_public_id primary key,
create_time wt_timestamp,
update_time wt_timestamp,
name text,
type text not null references iam_scope_type_enm(string) check(
(
type = 'organization'
and parent_id = null
)
or (
type = 'project'
and parent_id is not null
)
),
description text,
parent_id text references iam_scope(public_id) on delete cascade on update cascade
);
create table iam_scope_organization (
scope_id wt_public_id not null unique references iam_scope(public_id) on delete cascade on update cascade,
name text unique,
primary key(scope_id)
);
create table iam_scope_project (
scope_id wt_public_id not null references iam_scope(public_id) on delete cascade on update cascade,
parent_id wt_public_id not null references iam_scope_organization(scope_id) on delete cascade on update cascade,
name text,
unique(parent_id, name),
primary key(scope_id, parent_id)
);
create or replace function
iam_sub_scopes_func()
returns trigger
as $$
declare parent_type int;
begin
if new.type = 'organization' then
insert into iam_scope_organization (scope_id, name)
values
(new.public_id, new.name);
return new;
end if;
if new.type = 'project' then
insert into iam_scope_project (scope_id, parent_id, name)
values
(new.public_id, new.parent_id, new.name);
return new;
end if;
raise exception 'unknown scope type';
end;
$$ language plpgsql;
create trigger
iam_scope_insert
after
insert on iam_scope
for each row execute procedure iam_sub_scopes_func();
create or replace function
iam_immutable_scope_type_func()
returns trigger
as $$
declare parent_type int;
begin
if new.type != old.type then
raise exception 'scope type cannot be updated';
end if;
return new;
end;
$$ language plpgsql;
create trigger
iam_scope_update
before
update on iam_scope
for each row execute procedure iam_immutable_scope_type_func();
create trigger
update_time_column
before update on iam_scope
for each row execute procedure update_time_column();
create trigger
immutable_create_time
before
update on iam_scope
for each row execute procedure immutable_create_time_func();
create trigger
default_create_time_column
before
insert on iam_scope
for each row execute procedure default_create_time();
-- iam_sub_names will allow us to enforce the different name constraints for
-- organizations and projects via a before update trigger on the iam_scope
-- table.
create or replace function
iam_sub_names()
returns trigger
as $$
begin
if new.name != old.name then
if new.type = 'organization' then
update iam_scope_organization set name = new.name where scope_id = old.public_id;
return new;
end if;
if new.type = 'project' then
update iam_scope_project set name = new.name where scope_id = old.public_id;
return new;
end if;
raise exception 'unknown scope type';
end if;
return new;
end;
$$ language plpgsql;
create trigger
iam_sub_names
before
update on iam_scope
for each row execute procedure iam_sub_names();
create table iam_user (
public_id wt_public_id not null primary key,
create_time wt_timestamp,
update_time wt_timestamp,
name text,
description text,
scope_id wt_public_id not null references iam_scope_organization(scope_id) on delete cascade on update cascade,
unique(name, scope_id),
disabled boolean not null default false
);
create trigger
update_time_column
before update on iam_user
for each row execute procedure update_time_column();
create trigger
immutable_create_time
before
update on iam_user
for each row execute procedure immutable_create_time_func();
create trigger
default_create_time_column
before
insert on iam_user
for each row execute procedure default_create_time();
create table iam_role (
public_id wt_public_id not null primary key,
create_time wt_timestamp,
update_time wt_timestamp,
name text,
description text,
scope_id wt_public_id not null references iam_scope(public_id) on delete cascade on update cascade,
unique(name, scope_id),
disabled boolean not null default false
);
create trigger
update_time_column
before update on iam_role
for each row execute procedure update_time_column();
create trigger
immutable_create_time
before
update on iam_role
for each row execute procedure immutable_create_time_func();
create trigger
default_create_time_column
before
insert on iam_role
for each row execute procedure default_create_time();
create table iam_group (
public_id wt_public_id not null primary key,
create_time wt_timestamp,
update_time wt_timestamp,
name text,
description text,
scope_id wt_public_id not null references iam_scope(public_id) on delete cascade on update cascade,
unique(name, scope_id),
disabled boolean not null default false
);
create trigger
update_time_column
before update on iam_group
for each row execute procedure update_time_column();
create trigger
immutable_create_time
before
update on iam_group
for each row execute procedure immutable_create_time_func();
create trigger
default_create_time_column
before
insert on iam_group
for each row execute procedure default_create_time();
commit;