From 90dfb5f015d5f6ad5b86453904d82802cc7bbc5e Mon Sep 17 00:00:00 2001 From: Sorawis Nilparuk Date: Thu, 26 Dec 2024 15:45:13 -0800 Subject: [PATCH 01/29] add migration scripts --- ...reate_objects_for_normalized_grants.up.sql | 461 ++++++++++++++++++ 1 file changed, 461 insertions(+) create mode 100644 internal/db/schema/migrations/oss/postgres/94/01_create_objects_for_normalized_grants.up.sql diff --git a/internal/db/schema/migrations/oss/postgres/94/01_create_objects_for_normalized_grants.up.sql b/internal/db/schema/migrations/oss/postgres/94/01_create_objects_for_normalized_grants.up.sql new file mode 100644 index 0000000000..94a58c8ec5 --- /dev/null +++ b/internal/db/schema/migrations/oss/postgres/94/01_create_objects_for_normalized_grants.up.sql @@ -0,0 +1,461 @@ +begin; + +create domain wt_version as bigint; +create domain wt_timestamp as timestamptz; +create domain wt_scope_id as text + check ( + length(trim(value)) > 10 or value = 'global' + ); + +create domain wt_role_id as text not null + check ( + length(trim(value)) > 10 + ); + +create table iam_scope_type_enm +( + string text not null primary key + constraint only_predefined_scope_types_allowed + check (string in ('unknown', 'global', 'org', 'project')) +); + +insert into iam_scope_type_enm (string) +values + ('unknown'), + ('global'), + ('org'), + ('project'); + + +create table iam_scope +( + public_id wt_scope_id primary key, + create_time wt_timestamp, + update_time wt_timestamp, + name text, + type text not null + constraint only_known_scope_types_allowed + references iam_scope_type_enm (string) + check ( + ( + type = 'global' + and parent_id is null + ) + or ( + type = 'org' + and parent_id = 'global' + ) + or ( + type = 'project' + and parent_id is not null + and parent_id != 'global' + ) + ), +description text, +parent_id text + references iam_scope (public_id) + on delete cascade + on update cascade, + version wt_version +); + +create table iam_scope_global +( + scope_id wt_scope_id primary key + constraint only_one_global_scope_allowed + references iam_scope (public_id) + on delete cascade + on update cascade + check ( + scope_id = 'global' + ), + name text unique +); + +create table iam_scope_org +( + scope_id wt_scope_id not null primary key + references iam_scope (public_id) + on delete cascade + on update cascade, + parent_id wt_scope_id not null + references iam_scope_global (scope_id) + on delete cascade + on update cascade, + name text, + unique (parent_id, name) +); + +create table iam_scope_project +( + scope_id wt_scope_id null null primary key + references iam_scope (public_id) + on delete cascade + on update cascade, + parent_id wt_scope_id not null + references iam_scope_org (scope_id) + on delete cascade + on update cascade, + name text, + unique (parent_id, name) +); + +create or replace function iam_sub_scopes_func() returns trigger +as $$ + declare parent_type int; + begin + if new.type = 'global' then + insert into iam_scope_global + (scope_id, name) + values (new.public_id, new.name); + return new; + end if; + if new.type = 'org' then + insert into iam_scope_org + (scope_id, parent_id, name) + values (new.public_id, new.parent_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; +comment on function iam_sub_scopes_func() is + 'iam_sub_scopes_func is a function that inserts scopes into its respective scope type table'; + +create trigger iam_scope_insert after insert on iam_scope + for each row execute procedure iam_sub_scopes_func(); + +insert into iam_scope + (public_id, name, type, parent_id) +values + ('global', 'Global', 'global', null); + +-- base table for iam_role +create table iam_role +( + public_id wt_role_id not null primary key, + scope_id wt_scope_id + references iam_scope (public_id) + on delete cascade + on update cascade +); + +create table iam_role_global_grant_scope_enm +( + name text not null primary key + constraint only_predefined_scope_types_allowed + check ( + name in ('descendants', 'children', 'individual') + ) +); + +insert into iam_role_global_grant_scope_enm (name) +values + ('descendants'), + ('children'), + ('individual'); + +create or replace function insert_role_subtype() returns trigger +as $$ +begin + insert into iam_role + (public_id, scope_id) + values + (new.public_id, new.scope_id); + return new; +end; +$$ language plpgsql; +comment on function insert_role_subtype() is + 'insert_role_subtype inserts a role to the appropriate subtype table'; + + + +-- global iam_role must have a scope_id of global +create table iam_role_global +( + public_id wt_role_id not null primary key + references iam_role (public_id) + on delete cascade + on update cascade, + scope_id wt_scope_id + references iam_scope_global (scope_id) + on delete cascade + on update cascade, + name text, + description text, + grant_this_role_scope boolean not null, + grant_scope text + references iam_role_global_grant_scope_enm (name) + on delete restrict + on update cascade, + version wt_version, + unique (public_id, grant_scope) +); + +create trigger insert_role_subtype before insert on iam_role_global + for each row execute procedure insert_role_subtype(); + +create table iam_role_global_individual_grant_scope +( + role_id wt_role_id + references iam_role_global (public_id) + on delete cascade + on update cascade + -- grant_scope is used for constraint checking. + -- This restricts the grant_scope to be 'individual' + -- and since it is also a foreign key to the iam_role_global + -- grant_scope, it ensures that iam_role_global is set to 'individual' + -- if this table is populated for the corresponding role. + , + grant_scope text + constraint only_individual_grant_scope_allowed + check (grant_scope = 'individual'), + scope_id wt_scope_id + references iam_scope (public_id) + on delete cascade + on update cascade + constraint not_global_scope + check (scope_id != 'global'), + foreign key (role_id, grant_scope) + references iam_role_global (public_id, grant_scope) +); + +create table iam_role_org_grant_scope_enm +( + name text not null primary key + constraint only_predefined_scope_types_allowed + check ( + name in ( + 'children', + 'individual' + ) + ) +); + +insert into iam_role_org_grant_scope_enm (name) +values + ('children'), + ('individual'); + +create table iam_role_org +( + public_id wt_role_id not null primary key + references iam_role (public_id) + on delete cascade + on update cascade, + scope_id wt_scope_id + references iam_scope_org (scope_id) + on delete cascade + on update cascade, + name text, + description text, + grant_this_role_scope boolean not null, + grant_scope text + references iam_role_org_grant_scope_enm (name) + on delete restrict + on update cascade, + version wt_version, + unique (public_id, grant_scope) +); + +create trigger insert_role_subtype before insert on iam_role_org + for each row execute procedure insert_role_subtype(); + +create table iam_role_org_individual_grant_scope +( + role_id wt_role_id + references iam_role_org (public_id) + on delete cascade + on update cascade + -- grant_scope is used for constraint checking. + -- This restricts the grant_scope to be 'individual' + -- and since it is also a foreign key to the iam_role_org + -- grant_scope, it ensures that iam_role_org is set to 'individual' + -- if this table is populated for the corresponding role. + , + grant_scope text + constraint only_individual_grant_scope_allowed + check (grant_scope = 'individual'), + scope_id wt_scope_id + references iam_scope_project (scope_id) + -- TODO: ensure the project's parent is the role's scope. + on delete cascade + on update cascade, + foreign key (role_id, grant_scope) + references iam_role_org (public_id, grant_scope) +); + +create table iam_role_project +( + public_id wt_role_id not null primary key + references iam_role (public_id) + on delete cascade + on update cascade, + scope_id wt_scope_id not null + references iam_scope_project (scope_id) + on delete cascade + on update cascade, + name text, + description text, + version wt_version +); +create trigger insert_role_subtype before insert on iam_role_project + for each row execute procedure insert_role_subtype(); + +create table resource_enm +( + string text not null primary key +); + +insert into resource_enm (string) +values + ('*'), + ('unknown'), + ('scope'), + ('user'), + ('group'), + ('role'), + ('auth-method'), + ('account'), + ('auth-token'), + ('host-catalog'), + ('host-set'), + ('host'), + ('target'), + ('controller'), + ('worker'), + ('session'), + ('session-recording'), + ('managed-group'), + ('credential-store'), + ('credential-library'), + ('credential'), + ('storage-bucket'), + ('policy'), + ('billing'), + ('alias'); + +-- iam_grant is the root table for a grant value object. +-- A grant can only reference a single resource, including the special +-- strings "*" to indicate "all" resources, and "unknown" when no resource is set. +-- The set of actions that are included in the grant +-- get associated with the grant in the iam_grant_action +-- table. We could potentially have a trigger function on insert +-- that parses the grant and inserts the appropriate rows into the other tables. +-- This should be immutable, and there isn't really a need to delete them. +create table iam_grant +( + canonical_grant text not null primary key, + resource text not null + references resource_enm (string) + on delete restrict + on update cascade +); +create index iam_grant_resource_ix + on iam_grant (resource); + +create function set_resource() returns trigger +as $$ +declare resource text[]; +begin + select regexp_matches(new.canonical_grant, 'type=([^;]+);') + into resource; + if resource is null then + new.resource = 'unknown'; + else + new.resource = resource[1]; + end if; + return new; +end +$$ language plpgsql; + + +create trigger set_resource before insert on iam_grant + for each row execute procedure set_resource(); + +create table iam_role_grant +( + role_id wt_role_id + references iam_role (public_id) + on delete cascade + on update cascade, + canonical_grant text + references iam_grant (canonical_grant) + on delete restrict + on update cascade, + raw_grant text, + primary key (canonical_grant, role_id) +); +create index iam_role_grant_canonical_grant_ix + on iam_role_grant (canonical_grant); + +create function upsert_canonical_grant() returns trigger +as $$ +begin + insert into iam_grant + (canonical_grant) + values + (new.canonical_grant) + on conflict do nothing; + return new; +end +$$ language plpgsql; + +create trigger upsert_canonical_grant before insert on iam_role_grant + for each row execute procedure upsert_canonical_grant(); + +create table iam_group +( + public_id text not null primary key, + name text, + description text, + scope_id wt_scope_id + references iam_scope (public_id) + on delete cascade + on update cascade +); + +create table iam_group_role +( + role_id wt_role_id + references iam_role (public_id) + on delete cascade + on update cascade, + group_id text + references iam_group (public_id) + on delete cascade + on update cascade, + primary key (role_id, group_id) +); + +create table iam_user +( + public_id text not null primary key, + name text, + description text, + scope_id wt_scope_id + references iam_scope (public_id) + on delete cascade + on update cascade +); + +create table iam_group_member_user +( + group_id text + references iam_group (public_id) + on delete cascade + on update cascade, + member_id text + references iam_user (public_id) + on delete cascade + on update cascade, + primary key (group_id, member_id) +); + +commit; \ No newline at end of file From 26d10a77913db1b3bcec1e0f9680d9c94f082fec Mon Sep 17 00:00:00 2001 From: Sorawis Nilparuk Date: Thu, 26 Dec 2024 16:31:44 -0800 Subject: [PATCH 02/29] delete duplicate resources --- ...reate_objects_for_normalized_grants.up.sql | 205 ------------------ 1 file changed, 205 deletions(-) diff --git a/internal/db/schema/migrations/oss/postgres/94/01_create_objects_for_normalized_grants.up.sql b/internal/db/schema/migrations/oss/postgres/94/01_create_objects_for_normalized_grants.up.sql index 94a58c8ec5..66fb575a63 100644 --- a/internal/db/schema/migrations/oss/postgres/94/01_create_objects_for_normalized_grants.up.sql +++ b/internal/db/schema/migrations/oss/postgres/94/01_create_objects_for_normalized_grants.up.sql @@ -1,150 +1,6 @@ begin; -create domain wt_version as bigint; -create domain wt_timestamp as timestamptz; -create domain wt_scope_id as text - check ( - length(trim(value)) > 10 or value = 'global' - ); - -create domain wt_role_id as text not null - check ( - length(trim(value)) > 10 - ); - -create table iam_scope_type_enm -( - string text not null primary key - constraint only_predefined_scope_types_allowed - check (string in ('unknown', 'global', 'org', 'project')) -); - -insert into iam_scope_type_enm (string) -values - ('unknown'), - ('global'), - ('org'), - ('project'); - - -create table iam_scope -( - public_id wt_scope_id primary key, - create_time wt_timestamp, - update_time wt_timestamp, - name text, - type text not null - constraint only_known_scope_types_allowed - references iam_scope_type_enm (string) - check ( - ( - type = 'global' - and parent_id is null - ) - or ( - type = 'org' - and parent_id = 'global' - ) - or ( - type = 'project' - and parent_id is not null - and parent_id != 'global' - ) - ), -description text, -parent_id text - references iam_scope (public_id) - on delete cascade - on update cascade, - version wt_version -); - -create table iam_scope_global -( - scope_id wt_scope_id primary key - constraint only_one_global_scope_allowed - references iam_scope (public_id) - on delete cascade - on update cascade - check ( - scope_id = 'global' - ), - name text unique -); - -create table iam_scope_org -( - scope_id wt_scope_id not null primary key - references iam_scope (public_id) - on delete cascade - on update cascade, - parent_id wt_scope_id not null - references iam_scope_global (scope_id) - on delete cascade - on update cascade, - name text, - unique (parent_id, name) -); - -create table iam_scope_project -( - scope_id wt_scope_id null null primary key - references iam_scope (public_id) - on delete cascade - on update cascade, - parent_id wt_scope_id not null - references iam_scope_org (scope_id) - on delete cascade - on update cascade, - name text, - unique (parent_id, name) -); - -create or replace function iam_sub_scopes_func() returns trigger -as $$ - declare parent_type int; - begin - if new.type = 'global' then - insert into iam_scope_global - (scope_id, name) - values (new.public_id, new.name); - return new; - end if; - if new.type = 'org' then - insert into iam_scope_org - (scope_id, parent_id, name) - values (new.public_id, new.parent_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; -comment on function iam_sub_scopes_func() is - 'iam_sub_scopes_func is a function that inserts scopes into its respective scope type table'; - -create trigger iam_scope_insert after insert on iam_scope - for each row execute procedure iam_sub_scopes_func(); - -insert into iam_scope - (public_id, name, type, parent_id) -values - ('global', 'Global', 'global', null); - -- base table for iam_role -create table iam_role -( - public_id wt_role_id not null primary key, - scope_id wt_scope_id - references iam_scope (public_id) - on delete cascade - on update cascade -); create table iam_role_global_grant_scope_enm ( @@ -379,19 +235,6 @@ $$ language plpgsql; create trigger set_resource before insert on iam_grant for each row execute procedure set_resource(); -create table iam_role_grant -( - role_id wt_role_id - references iam_role (public_id) - on delete cascade - on update cascade, - canonical_grant text - references iam_grant (canonical_grant) - on delete restrict - on update cascade, - raw_grant text, - primary key (canonical_grant, role_id) -); create index iam_role_grant_canonical_grant_ix on iam_role_grant (canonical_grant); @@ -410,52 +253,4 @@ $$ language plpgsql; create trigger upsert_canonical_grant before insert on iam_role_grant for each row execute procedure upsert_canonical_grant(); -create table iam_group -( - public_id text not null primary key, - name text, - description text, - scope_id wt_scope_id - references iam_scope (public_id) - on delete cascade - on update cascade -); - -create table iam_group_role -( - role_id wt_role_id - references iam_role (public_id) - on delete cascade - on update cascade, - group_id text - references iam_group (public_id) - on delete cascade - on update cascade, - primary key (role_id, group_id) -); - -create table iam_user -( - public_id text not null primary key, - name text, - description text, - scope_id wt_scope_id - references iam_scope (public_id) - on delete cascade - on update cascade -); - -create table iam_group_member_user -( - group_id text - references iam_group (public_id) - on delete cascade - on update cascade, - member_id text - references iam_user (public_id) - on delete cascade - on update cascade, - primary key (group_id, member_id) -); - commit; \ No newline at end of file From 5bd0a972544456ee4679ca01996ff09bef154b97 Mon Sep 17 00:00:00 2001 From: Sorawis Nilparuk Date: Thu, 26 Dec 2024 16:34:15 -0800 Subject: [PATCH 03/29] fix color persona test setup --- internal/db/sqltest/initdb.d/01_colors_persona.sql | 5 +++++ 1 file changed, 5 insertions(+) diff --git a/internal/db/sqltest/initdb.d/01_colors_persona.sql b/internal/db/sqltest/initdb.d/01_colors_persona.sql index fba8d7d947..1963aa90b0 100644 --- a/internal/db/sqltest/initdb.d/01_colors_persona.sql +++ b/internal/db/sqltest/initdb.d/01_colors_persona.sql @@ -32,6 +32,11 @@ -- optional or non-standard columns. begin; + -- Add additional resource type used in this test + insert into resource_enm (string) + values + ('color'); + -- Add organizations insert into iam_scope (parent_id, type, public_id, name) From d4ed3651b3a33b70cc0b4f97fe0cd47b418288ff Mon Sep 17 00:00:00 2001 From: Sorawis Nilparuk Date: Thu, 26 Dec 2024 16:52:43 -0800 Subject: [PATCH 04/29] fix sqltest setup with new iam_grant --- internal/db/sqltest/initdb.d/01_colors_persona.sql | 5 +++-- internal/db/sqltest/initdb.d/02_wtt_load.sql | 6 ++++++ 2 files changed, 9 insertions(+), 2 deletions(-) diff --git a/internal/db/sqltest/initdb.d/01_colors_persona.sql b/internal/db/sqltest/initdb.d/01_colors_persona.sql index 1963aa90b0..f918664a82 100644 --- a/internal/db/sqltest/initdb.d/01_colors_persona.sql +++ b/internal/db/sqltest/initdb.d/01_colors_persona.sql @@ -32,8 +32,9 @@ -- optional or non-standard columns. begin; - -- Add additional resource type used in this test - insert into resource_enm (string) + -- setup resource for iam_grant + insert into resource_enm + (string) values ('color'); diff --git a/internal/db/sqltest/initdb.d/02_wtt_load.sql b/internal/db/sqltest/initdb.d/02_wtt_load.sql index a64790254a..62e76ee238 100644 --- a/internal/db/sqltest/initdb.d/02_wtt_load.sql +++ b/internal/db/sqltest/initdb.d/02_wtt_load.sql @@ -2,6 +2,12 @@ -- SPDX-License-Identifier: BUSL-1.1 begin; + -- setup resource for iam_grant + insert into resource_enm + (string) + values + ('widget'); + -- wtt_load populates tables for the given test persona and set of aggregates. -- Valid personas are: -- * widgets From a4627051d67dac5a80558a1793922c1280c857c1 Mon Sep 17 00:00:00 2001 From: Sorawis Nilparuk Date: Thu, 26 Dec 2024 16:57:57 -0800 Subject: [PATCH 05/29] refactor makefiles for sqltest --- internal/db/sqltest/Makefile | 37 ++++++++++++++++++------------------ 1 file changed, 19 insertions(+), 18 deletions(-) diff --git a/internal/db/sqltest/Makefile b/internal/db/sqltest/Makefile index 3633401728..95d652b6fb 100644 --- a/internal/db/sqltest/Makefile +++ b/internal/db/sqltest/Makefile @@ -16,29 +16,30 @@ endif # See: https://pgtap.org/pg_prove.html PROVE_OPTS ?= -TESTS ?= tests/setup/*.sql \ - tests/org/*.sql \ - tests/wh/*/*.sql \ - tests/sentinel/*.sql \ - tests/credential/*/*.sql \ - tests/session/*.sql \ - tests/account/*/*.sql \ - tests/target/*.sql \ - tests/controller/*.sql \ - tests/hcp/*/*.sql \ +TESTS ?= tests/account/*/*.sql \ + tests/alias/*.sql \ + tests/auth/*/*.sql \ tests/census/*.sql \ - tests/kms/*.sql \ - tests/storage/*.sql \ + tests/controller/*.sql \ + tests/credential/*/*.sql \ tests/domain/*.sql \ + tests/hcp/*/*.sql \ tests/history/*.sql \ - tests/recording/*.sql \ - tests/alias/*.sql \ - tests/auth/*/*.sql \ - tests/purge/*.sql \ + tests/host/*.sql \ + tests/iam/*.sql \ + tests/kms/*.sql \ + tests/org/*.sql \ tests/pagination/*.sql \ tests/policy/*.sql \ - tests/host/*.sql \ - tests/server/*.sql + tests/purge/*.sql \ + tests/recording/*.sql \ + tests/sentinel/*.sql \ + tests/server/*.sql \ + tests/session/*.sql \ + tests/setup/*.sql \ + tests/storage/*.sql \ + tests/target/*.sql \ + tests/wh/*/*.sql \ POSTGRES_DOCKER_IMAGE_BASE ?= postgres From 7299dd503cfd28655386b25d7d082d823f2d7253 Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Fri, 10 Jan 2025 10:07:35 -0500 Subject: [PATCH 06/29] feat(db): split up DB migration & add sql tests --- .../postgres/100/01_iam_role_global.up.sql | 111 ++++++++ .../oss/postgres/100/02_iam_role_org.up.sql | 119 ++++++++ .../postgres/100/03_iam_role_project.up.sql | 26 ++ .../oss/postgres/100/04_resource.up.sql | 38 +++ .../oss/postgres/100/05_iam_grant.up.sql | 44 +++ .../oss/postgres/100/06_iam_role_grant.up.sql | 24 ++ ...reate_objects_for_normalized_grants.up.sql | 256 ------------------ internal/db/sqltest/Makefile | 4 +- .../db/sqltest/tests/iam/iam_role_global.sql | 157 +++++++++++ .../db/sqltest/tests/iam/iam_role_org.sql | 2 + 10 files changed, 523 insertions(+), 258 deletions(-) create mode 100644 internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql create mode 100644 internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql create mode 100644 internal/db/schema/migrations/oss/postgres/100/03_iam_role_project.up.sql create mode 100644 internal/db/schema/migrations/oss/postgres/100/04_resource.up.sql create mode 100644 internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql create mode 100644 internal/db/schema/migrations/oss/postgres/100/06_iam_role_grant.up.sql delete mode 100644 internal/db/schema/migrations/oss/postgres/94/01_create_objects_for_normalized_grants.up.sql create mode 100644 internal/db/sqltest/tests/iam/iam_role_global.sql create mode 100644 internal/db/sqltest/tests/iam/iam_role_org.sql diff --git a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql new file mode 100644 index 0000000000..e67afcc39c --- /dev/null +++ b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql @@ -0,0 +1,111 @@ +-- Copyright (c) HashiCorp, Inc. +-- SPDX-License-Identifier: BUSL-1.1 + +begin; + + create table iam_role_global_grant_scope_enm ( + name text not null primary key + constraint only_predefined_scope_types_allowed + check( + name in ( + 'descendants', + 'children', + 'individual' + ) + ) + ); + + insert into iam_role_global_grant_scope_enm (name) + values + ('descendants'), + ('children'), + ('individual'); + + create or replace function insert_role_subtype() returns trigger + as $$ + begin + insert into iam_role + (public_id, scope_id) + values + (new.public_id, new.scope_id); + return new; + end; + $$ language plpgsql; + + create or replace function insert_grant_scope_update_time() returns trigger + as $$ + begin + if (new.grant_this_role_scope != old.grant_this_role_scope) + or (new.grant_scope != old.grant_scope) then + -- only update timestamp if one of the relevant columns have changed + new.grant_scope_update_time = now(); + else + -- if neither columns have changed, keep the old timestamp + new.grant_scope_update_time = old.grant_scope_update_time; + end if; + return new; + end; + $$ language plpgsql; + + -- global iam_role must have a scope_id of global + create table iam_role_global ( + public_id wt_role_id not null primary key + constraint iam_role_fkey + references iam_role(public_id) + on delete cascade + on update cascade, + scope_id wt_scope_id + constraint iam_scope_global_fkey + references iam_scope_global(scope_id) + on delete cascade + on update cascade, + name text, + description text, + grant_this_role_scope boolean not null default false, + grant_scope text + constraint iam_role_global_grant_scope_enm_fkey + references iam_role_global_grant_scope_enm(name) + on delete restrict + on update cascade, + version wt_version, + grant_scope_update_time wt_timestamp, + unique(public_id, grant_scope) + ); + + create trigger insert_role_subtype before insert on iam_role_global + for each row execute procedure insert_role_subtype(); + + create trigger insert_iam_role_global_grant_scope_update_time before update on iam_role_global + for each row execute procedure insert_grant_scope_update_time(); + + create table iam_role_global_individual_grant_scope ( + role_id wt_role_id + constraint iam_role_global_fkey + references iam_role_global(public_id) + on delete cascade + on update cascade, + -- grant_scope is used for constraint checking. + -- This restricts the grant_scope to be 'individual' + -- and since it is also a foreign key to the iam_role_global + -- grant_scope, it ensures that iam_role_global is set to 'individual' + -- if this table is populated for the corresponding role. + grant_scope text + constraint only_individual_grant_scope_allowed + check( + grant_scope = 'individual' + ), + scope_id wt_scope_id + constraint iam_scope_fkey + references iam_scope(public_id) + on delete cascade + on update cascade + constraint scope_id_is_not_global + check( + scope_id != 'global' + ), + constraint iam_role_global_grant_scope_fkey + foreign key (role_id, grant_scope) + references iam_role_global(public_id, grant_scope) + ); + +commit; \ No newline at end of file diff --git a/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql b/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql new file mode 100644 index 0000000000..6944d88aef --- /dev/null +++ b/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql @@ -0,0 +1,119 @@ +-- Copyright (c) HashiCorp, Inc. +-- SPDX-License-Identifier: BUSL-1.1 + +begin; + + create table iam_role_org_grant_scope_enm ( + name text not null primary key + constraint only_predefined_scope_types_allowed + check( + name in ( + 'children', + 'individual' + ) + ) + ); + + insert into iam_role_org_grant_scope_enm (name) + values + ('children'), + ('individual'); + + create table iam_role_org ( + public_id wt_role_id not null primary key + constraint iam_role_fkey + references iam_role(public_id) + on delete cascade + on update cascade, + scope_id wt_scope_id + constraint iam_scope_org_fkey + references iam_scope_org(scope_id) + on delete cascade + on update cascade, + name text, + description text, + grant_this_role_scope boolean not null, + grant_scope text + constraint iam_role_org_grant_scope_enm_fkey + references iam_role_org_grant_scope_enm(name) + on delete restrict + on update cascade, + version wt_version, + grant_scope_update_time wt_timestamp, + unique(public_id, grant_scope) + ); + + create trigger insert_role_subtype before insert on iam_role_org + for each row execute procedure insert_role_subtype(); + + create trigger insert_iam_role_org_grant_scope_update_time before update on iam_role_org + for each row execute procedure insert_grant_scope_update_time(); + + create table iam_role_org_individual_grant_scope ( + role_id wt_role_id + constraint iam_role_org_fkey + references iam_role_org(public_id) + on delete cascade + on update cascade, + -- grant_scope is used for constraint checking. + -- This restricts the grant_scope to be 'individual' + -- and since it is also a foreign key to the iam_role_org + -- grant_scope, it ensures that iam_role_org is set to 'individual' + -- if this table is populated for the corresponding role. + grant_scope text + constraint only_individual_grant_scope_allowed + check( + grant_scope = 'individual' + ), + scope_id wt_scope_id + constraint iam_scope_org_fkey + references iam_scope_project(scope_id) + on delete cascade + on update cascade, + constraint iam_role_org_grant_scope_fkey + foreign key (role_id, grant_scope) + references iam_role_org(public_id, grant_scope) + ); + + -- ensure the project's parent is the role's scope + create or replace function ensure_project_belongs_to_org() returns trigger + as $$ + declare + org_scope_id text; + project_parent_id text; + begin + -- Find the org scope for this role + select scope_id + into org_scope_id + from iam_role_org + where public_id = new.role_id; + + if org_scope_id is null then + raise exception 'role % not found in iam_role_org', new.role_id; + end if; + + -- Find the project parent for the inserted scope_id + select parent_id + into project_parent_id + from iam_scope_project + where scope_id = new.scope_id; + + if project_parent_id is null then + raise exception 'project scope_id % not found in iam_scope_project', new.scope_id; + end if; + + -- Compare parent_id with the org scope + if project_parent_id != org_scope_id then + raise exception 'project % belongs to a different org', + new.scope_id; + end if; + + return new; + end; + $$ language plpgsql; + + + create trigger ensure_project_belongs_to_org before insert or update on iam_role_org_individual_grant_scope + for each row execute procedure ensure_project_belongs_to_org(); + +commit; \ No newline at end of file diff --git a/internal/db/schema/migrations/oss/postgres/100/03_iam_role_project.up.sql b/internal/db/schema/migrations/oss/postgres/100/03_iam_role_project.up.sql new file mode 100644 index 0000000000..b15ddc424c --- /dev/null +++ b/internal/db/schema/migrations/oss/postgres/100/03_iam_role_project.up.sql @@ -0,0 +1,26 @@ +-- Copyright (c) HashiCorp, Inc. +-- SPDX-License-Identifier: BUSL-1.1 + +begin; + + create table iam_role_project ( + public_id wt_role_id not null primary key + constraint iam_role_fkey + references iam_role(public_id) + on delete cascade + on update cascade, + scope_id wt_scope_id not null + constraint iam_scope_project_fkey + references iam_scope_project(scope_id) + on delete cascade + on update cascade, + name text, + description text, + version wt_version, + grant_scope_update_time wt_timestamp + ); + + create trigger insert_iam_role_project_grant_scope_update_time before update on iam_role_project + for each row execute procedure insert_grant_scope_update_time(); + +commit; \ No newline at end of file diff --git a/internal/db/schema/migrations/oss/postgres/100/04_resource.up.sql b/internal/db/schema/migrations/oss/postgres/100/04_resource.up.sql new file mode 100644 index 0000000000..b4b28caf30 --- /dev/null +++ b/internal/db/schema/migrations/oss/postgres/100/04_resource.up.sql @@ -0,0 +1,38 @@ +-- Copyright (c) HashiCorp, Inc. +-- SPDX-License-Identifier: BUSL-1.1 + +begin; + + create table resource_enm ( + string text not null primary key + ); + + insert into resource_enm (string) + values + ('*'), + ('unknown'), + ('scope'), + ('user'), + ('group'), + ('role'), + ('auth-method'), + ('account'), + ('auth-token'), + ('host-catalog'), + ('host-set'), + ('host'), + ('target'), + ('controller'), + ('worker'), + ('session'), + ('session-recording'), + ('managed-group'), + ('credential-store'), + ('credential-library'), + ('credential'), + ('storage-bucket'), + ('policy'), + ('billing'), + ('alias'); + +commit; \ No newline at end of file diff --git a/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql b/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql new file mode 100644 index 0000000000..329dc64b8b --- /dev/null +++ b/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql @@ -0,0 +1,44 @@ +-- Copyright (c) HashiCorp, Inc. +-- SPDX-License-Identifier: BUSL-1.1 + +begin; + + -- iam_grant is the root table for a grant value object. + -- A grant can only reference a single resource, including the special + -- strings "*" to indicate "all" resources, and "unknown" when no resource is set. + -- The set of actions that are included in the grant + -- get associated with the grant in the iam_grant_action + -- table. We could potentially have a trigger function on insert + -- that parses the grant and inserts the appropriate rows into the other tables. + -- This should be immutable, and there isn't really a need to delete them. + create table iam_grant ( + canonical_grant text not null primary key, + resource text not null + constraint resource_enm_fkey + references resource_enm(string) + on delete restrict + on update cascade + ); + + create index iam_grant_resource_ix + on iam_grant (resource); + + create function set_resource() returns trigger + as $$ + declare resource text[]; + begin + select regexp_matches(new.canonical_grant, 'type=([^;]+);') + into resource; + if resource is null then + new.resource = 'unknown'; + else + new.resource = resource[1]; + end if; + return new; + end + $$ language plpgsql; + + create trigger set_resource before insert on iam_grant + for each row execute procedure set_resource(); + +commit; \ No newline at end of file diff --git a/internal/db/schema/migrations/oss/postgres/100/06_iam_role_grant.up.sql b/internal/db/schema/migrations/oss/postgres/100/06_iam_role_grant.up.sql new file mode 100644 index 0000000000..80f1df50a2 --- /dev/null +++ b/internal/db/schema/migrations/oss/postgres/100/06_iam_role_grant.up.sql @@ -0,0 +1,24 @@ +-- Copyright (c) HashiCorp, Inc. +-- SPDX-License-Identifier: BUSL-1.1 + +begin; + + create index iam_role_grant_canonical_grant_ix + on iam_role_grant (canonical_grant); + + create function upsert_canonical_grant() returns trigger + as $$ + begin + insert into iam_grant + (canonical_grant) + values + (new.canonical_grant) + on conflict do nothing; + return new; + end + $$ language plpgsql; + + create trigger upsert_canonical_grant before insert on iam_role_grant + for each row execute procedure upsert_canonical_grant(); + +commit; \ No newline at end of file diff --git a/internal/db/schema/migrations/oss/postgres/94/01_create_objects_for_normalized_grants.up.sql b/internal/db/schema/migrations/oss/postgres/94/01_create_objects_for_normalized_grants.up.sql deleted file mode 100644 index 66fb575a63..0000000000 --- a/internal/db/schema/migrations/oss/postgres/94/01_create_objects_for_normalized_grants.up.sql +++ /dev/null @@ -1,256 +0,0 @@ -begin; - --- base table for iam_role - -create table iam_role_global_grant_scope_enm -( - name text not null primary key - constraint only_predefined_scope_types_allowed - check ( - name in ('descendants', 'children', 'individual') - ) -); - -insert into iam_role_global_grant_scope_enm (name) -values - ('descendants'), - ('children'), - ('individual'); - -create or replace function insert_role_subtype() returns trigger -as $$ -begin - insert into iam_role - (public_id, scope_id) - values - (new.public_id, new.scope_id); - return new; -end; -$$ language plpgsql; -comment on function insert_role_subtype() is - 'insert_role_subtype inserts a role to the appropriate subtype table'; - - - --- global iam_role must have a scope_id of global -create table iam_role_global -( - public_id wt_role_id not null primary key - references iam_role (public_id) - on delete cascade - on update cascade, - scope_id wt_scope_id - references iam_scope_global (scope_id) - on delete cascade - on update cascade, - name text, - description text, - grant_this_role_scope boolean not null, - grant_scope text - references iam_role_global_grant_scope_enm (name) - on delete restrict - on update cascade, - version wt_version, - unique (public_id, grant_scope) -); - -create trigger insert_role_subtype before insert on iam_role_global - for each row execute procedure insert_role_subtype(); - -create table iam_role_global_individual_grant_scope -( - role_id wt_role_id - references iam_role_global (public_id) - on delete cascade - on update cascade - -- grant_scope is used for constraint checking. - -- This restricts the grant_scope to be 'individual' - -- and since it is also a foreign key to the iam_role_global - -- grant_scope, it ensures that iam_role_global is set to 'individual' - -- if this table is populated for the corresponding role. - , - grant_scope text - constraint only_individual_grant_scope_allowed - check (grant_scope = 'individual'), - scope_id wt_scope_id - references iam_scope (public_id) - on delete cascade - on update cascade - constraint not_global_scope - check (scope_id != 'global'), - foreign key (role_id, grant_scope) - references iam_role_global (public_id, grant_scope) -); - -create table iam_role_org_grant_scope_enm -( - name text not null primary key - constraint only_predefined_scope_types_allowed - check ( - name in ( - 'children', - 'individual' - ) - ) -); - -insert into iam_role_org_grant_scope_enm (name) -values - ('children'), - ('individual'); - -create table iam_role_org -( - public_id wt_role_id not null primary key - references iam_role (public_id) - on delete cascade - on update cascade, - scope_id wt_scope_id - references iam_scope_org (scope_id) - on delete cascade - on update cascade, - name text, - description text, - grant_this_role_scope boolean not null, - grant_scope text - references iam_role_org_grant_scope_enm (name) - on delete restrict - on update cascade, - version wt_version, - unique (public_id, grant_scope) -); - -create trigger insert_role_subtype before insert on iam_role_org - for each row execute procedure insert_role_subtype(); - -create table iam_role_org_individual_grant_scope -( - role_id wt_role_id - references iam_role_org (public_id) - on delete cascade - on update cascade - -- grant_scope is used for constraint checking. - -- This restricts the grant_scope to be 'individual' - -- and since it is also a foreign key to the iam_role_org - -- grant_scope, it ensures that iam_role_org is set to 'individual' - -- if this table is populated for the corresponding role. - , - grant_scope text - constraint only_individual_grant_scope_allowed - check (grant_scope = 'individual'), - scope_id wt_scope_id - references iam_scope_project (scope_id) - -- TODO: ensure the project's parent is the role's scope. - on delete cascade - on update cascade, - foreign key (role_id, grant_scope) - references iam_role_org (public_id, grant_scope) -); - -create table iam_role_project -( - public_id wt_role_id not null primary key - references iam_role (public_id) - on delete cascade - on update cascade, - scope_id wt_scope_id not null - references iam_scope_project (scope_id) - on delete cascade - on update cascade, - name text, - description text, - version wt_version -); -create trigger insert_role_subtype before insert on iam_role_project - for each row execute procedure insert_role_subtype(); - -create table resource_enm -( - string text not null primary key -); - -insert into resource_enm (string) -values - ('*'), - ('unknown'), - ('scope'), - ('user'), - ('group'), - ('role'), - ('auth-method'), - ('account'), - ('auth-token'), - ('host-catalog'), - ('host-set'), - ('host'), - ('target'), - ('controller'), - ('worker'), - ('session'), - ('session-recording'), - ('managed-group'), - ('credential-store'), - ('credential-library'), - ('credential'), - ('storage-bucket'), - ('policy'), - ('billing'), - ('alias'); - --- iam_grant is the root table for a grant value object. --- A grant can only reference a single resource, including the special --- strings "*" to indicate "all" resources, and "unknown" when no resource is set. --- The set of actions that are included in the grant --- get associated with the grant in the iam_grant_action --- table. We could potentially have a trigger function on insert --- that parses the grant and inserts the appropriate rows into the other tables. --- This should be immutable, and there isn't really a need to delete them. -create table iam_grant -( - canonical_grant text not null primary key, - resource text not null - references resource_enm (string) - on delete restrict - on update cascade -); -create index iam_grant_resource_ix - on iam_grant (resource); - -create function set_resource() returns trigger -as $$ -declare resource text[]; -begin - select regexp_matches(new.canonical_grant, 'type=([^;]+);') - into resource; - if resource is null then - new.resource = 'unknown'; - else - new.resource = resource[1]; - end if; - return new; -end -$$ language plpgsql; - - -create trigger set_resource before insert on iam_grant - for each row execute procedure set_resource(); - -create index iam_role_grant_canonical_grant_ix - on iam_role_grant (canonical_grant); - -create function upsert_canonical_grant() returns trigger -as $$ -begin - insert into iam_grant - (canonical_grant) - values - (new.canonical_grant) - on conflict do nothing; - return new; -end -$$ language plpgsql; - -create trigger upsert_canonical_grant before insert on iam_role_grant - for each row execute procedure upsert_canonical_grant(); - -commit; \ No newline at end of file diff --git a/internal/db/sqltest/Makefile b/internal/db/sqltest/Makefile index 95d652b6fb..9b4ae30d5d 100644 --- a/internal/db/sqltest/Makefile +++ b/internal/db/sqltest/Makefile @@ -16,7 +16,8 @@ endif # See: https://pgtap.org/pg_prove.html PROVE_OPTS ?= -TESTS ?= tests/account/*/*.sql \ +TESTS ?= tests/setup/*.sql \ + tests/account/*/*.sql \ tests/alias/*.sql \ tests/auth/*/*.sql \ tests/census/*.sql \ @@ -36,7 +37,6 @@ TESTS ?= tests/account/*/*.sql \ tests/sentinel/*.sql \ tests/server/*.sql \ tests/session/*.sql \ - tests/setup/*.sql \ tests/storage/*.sql \ tests/target/*.sql \ tests/wh/*/*.sql \ diff --git a/internal/db/sqltest/tests/iam/iam_role_global.sql b/internal/db/sqltest/tests/iam/iam_role_global.sql new file mode 100644 index 0000000000..a972bf7799 --- /dev/null +++ b/internal/db/sqltest/tests/iam/iam_role_global.sql @@ -0,0 +1,157 @@ +-- Copyright (c) HashiCorp, Inc. +-- SPDX-License-Identifier: BUSL-1.1 + +begin; + select plan(14); + + -- Set up a scope to test against + insert into iam_scope + (type, public_id, parent_id) + values + ('org', 'o_1111111111', 'global'); + + -- remove any existing roles and their grant scopes, so we can test fresh + delete from iam_role; + + -------------------------------------------------------------------------------- + -- 1) testing iam_role_global table constraints and insert_role_subtype + -------------------------------------------------------------------------------- + + -- 1a) insert a valid row -> should succeed and insert_role_subtype trigger + prepare insert_valid_global_role as + insert into iam_role_global + (public_id, scope_id, grant_this_role_scope, grant_scope) + values + ('r_1111111111', 'global', true, 'children'); + select lives_ok('insert_valid_global_role'); + + -- verify it also created a row in base iam_role + select is(count(*), 1::bigint) from iam_role where public_id = 'r_1111111111'; + + -- 1e) try duplicate (public_id, grant_scope) => unique violation + prepare insert_dup_public_id_grant_scope as + insert into iam_role_global + (public_id, scope_id, grant_this_role_scope, grant_scope) + values + ('r_1111111111', 'global', true, 'children'); + select throws_like( + 'insert_dup_public_id_grant_scope', + 'duplicate key value violates unique constraint "iam_role_pkey"', + 'unique(public_id) is enforced' + ); + + -- 1b) invalid grant_scope (not in iam_role_global_grant_scope_enm table) + prepare insert_invalid_grant_scope as + insert into iam_role_global + (public_id, scope_id, grant_this_role_scope, grant_scope) + values + ('r_globeglobe', 'global', true, 'invalid_grant_scope'); + select throws_like( + 'insert_invalid_grant_scope', + 'insert or update on table "iam_role_global" violates foreign key constraint "iam_role_global_grant_scope_enm_fkey"', + 'invalid grant_scope must fail foreign key to iam_role_global_grant_scope_enm' + ); + + -- 1c) invalid scope_id -> must reference iam_scope_global(scope_id) + prepare insert_bad_scope_id as + insert into iam_role_global + (public_id, scope_id, grant_this_role_scope, grant_scope) + values + ('r_globeglobe', 'does_not_exist', true, 'individual'); + select throws_like( + 'insert_bad_scope_id', + 'insert or update on table "iam_role" violates foreign key constraint "iam_scope_scope_id_fkey"', + 'scope_id must exist in iam_scope_global(scope_id)' + ); + + -------------------------------------------------------------------------------- + -- 2) testing insert_grant_scope_update_time trigger + -------------------------------------------------------------------------------- + + -- 2a) clean up any previous data + delete from iam_role; + + -- 2b) insert a new row (grant_this_role_scope, grant_scope) => should initialize + prepare insert_with_grant_scope_update_time_set as + insert into iam_role_global + (public_id, scope_id, grant_this_role_scope, grant_scope, grant_scope_update_time) + values + ('r_1111111111', 'global', false, 'descendants', null); + select lives_ok('insert_with_grant_scope_update_time_set'); + + -- 2c) check if grant_scope_update_time is set + select is( + (select grant_scope_update_time is null from iam_role_global where public_id = 'r_1111111111'), + true, + 'grant_scope_update_time should be set with the default timestamp right after insert' + ); + + -- 2d) update grant_this_role_scope => trigger should update grant_scope_update_time timestamp + prepare update_grant_this_role_scope as + update iam_role_global + set grant_this_role_scope = true + where public_id = 'r_1111111111'; + select lives_ok('update_grant_this_role_scope'); + select is( + (select grant_scope_update_time is not null from iam_role_global where public_id = 'r_1111111111'), + true, + 'grant_scope_update_time should be set with the default timestamp right after insert' + ); + + -------------------------------------------------------------------------------- + -- 3) testing iam_role_global_individual_grant_scope table constraints + -------------------------------------------------------------------------------- + + --3a) insert invalid row: grant_scope != 'individual' + prepare insert_invalid_individual_grant_scope as + insert into iam_role_global_individual_grant_scope + (role_id, scope_id, grant_scope) + values + ('r_2111111111', 'descendants', 'global'); + select throws_like( + 'insert_invalid_individual_grant_scope', + 'new row for relation "iam_role_global_individual_grant_scope" violates check constraint "only_individual_grant_scope_allowed"', + 'check(grant_scope = "individual") is enforced' + ); + + -- 3b) insert invalid row with a scope_id that is not global + prepare insert_invalid_iam_role_global_individual_grant_scope as + insert into iam_role_global_individual_grant_scope + (role_id, grant_scope, scope_id) + values + ('r_1111111111', 'individual', 'o_1111111111'); + select throws_like( + 'insert_invalid_iam_role_global_individual_grant_scope', + 'insert or update on table "iam_role_global_individual_grant_scope" violates foreign key constraint "iam_role_global_grant_scope_fkey"', + 'foreign key also enforces matching grant_scope=individual in iam_role_global' + ); + + -- 3c) insert invalid row where scope_id is 'global' + prepare insert_iam_role_global_individual_scope_id as + insert into iam_role_global_individual_grant_scope + (role_id, grant_scope, scope_id) + values + ('r_1111111111', 'individual', 'global'); + select throws_like( + 'insert_iam_role_global_individual_scope_id', + 'new row for relation "iam_role_global_individual_grant_scope" violates check constraint "scope_id_is_not_global"', + 'check(scope_id != ''global'') is enforced' + ); + + -- 3d) insert valid iam_role_global_individual_grant_scope + prepare insert_global_role_for_individual_scope as + insert into iam_role_global + (public_id, scope_id, grant_scope) + values + ('r_3111111111', 'global', 'individual'); + select lives_ok('insert_global_role_for_individual_scope'); + + prepare insert_valid_individual_org_scope as + insert into iam_role_global_individual_grant_scope + (role_id, grant_scope, scope_id) + values + ('r_3111111111', 'individual', 'o_1111111111'); + select lives_ok('insert_valid_individual_org_scope'); + + select * from finish(); +rollback; diff --git a/internal/db/sqltest/tests/iam/iam_role_org.sql b/internal/db/sqltest/tests/iam/iam_role_org.sql new file mode 100644 index 0000000000..44bac043bb --- /dev/null +++ b/internal/db/sqltest/tests/iam/iam_role_org.sql @@ -0,0 +1,2 @@ +-- Copyright (c) HashiCorp, Inc. +-- SPDX-License-Identifier: BUSL-1.1 \ No newline at end of file From 470a4636f2c13c8e979ab6ec9c551663d0aeddde Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Mon, 27 Jan 2025 14:31:22 -0500 Subject: [PATCH 07/29] add timestamp for grant_scope updates --- .../postgres/100/01_iam_role_global.up.sql | 23 +++++++++++++------ .../postgres/100/03_iam_role_project.up.sql | 6 +---- 2 files changed, 17 insertions(+), 12 deletions(-) diff --git a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql index e67afcc39c..c325d6545d 100644 --- a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql @@ -35,13 +35,18 @@ begin; create or replace function insert_grant_scope_update_time() returns trigger as $$ begin - if (new.grant_this_role_scope != old.grant_this_role_scope) - or (new.grant_scope != old.grant_scope) then - -- only update timestamp if one of the relevant columns have changed + if (new.grant_scope != old.grant_scope) then + new.grant_scope_update_time = now(); + end if; + return new; + end; + $$ language plpgsql; + + create or replace function insert_grant_this_role_scope_update_time() returns trigger + as $$ + begin + if (new.grant_this_role_scope != old.grant_this_role_scope) then new.grant_scope_update_time = now(); - else - -- if neither columns have changed, keep the old timestamp - new.grant_scope_update_time = old.grant_scope_update_time; end if; return new; end; @@ -68,6 +73,7 @@ begin; on delete restrict on update cascade, version wt_version, + grant_this_role_scope_update_time wt_timestamp, grant_scope_update_time wt_timestamp, unique(public_id, grant_scope) ); @@ -76,7 +82,10 @@ begin; for each row execute procedure insert_role_subtype(); create trigger insert_iam_role_global_grant_scope_update_time before update on iam_role_global - for each row execute procedure insert_grant_scope_update_time(); + for each row execute procedure insert_grant_scope_update_time(); + + create trigger insert_iam_role_global_grant_this_role_scope_update_time before update on iam_role_global + for each row execute procedure insert_grant_this_role_scope_update_time(); create table iam_role_global_individual_grant_scope ( role_id wt_role_id diff --git a/internal/db/schema/migrations/oss/postgres/100/03_iam_role_project.up.sql b/internal/db/schema/migrations/oss/postgres/100/03_iam_role_project.up.sql index b15ddc424c..017a02b9e3 100644 --- a/internal/db/schema/migrations/oss/postgres/100/03_iam_role_project.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/03_iam_role_project.up.sql @@ -16,11 +16,7 @@ begin; on update cascade, name text, description text, - version wt_version, - grant_scope_update_time wt_timestamp + version wt_version ); - create trigger insert_iam_role_project_grant_scope_update_time before update on iam_role_project - for each row execute procedure insert_grant_scope_update_time(); - commit; \ No newline at end of file From 35ad253b9c3b98528705000c5f9308592bef185d Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Mon, 27 Jan 2025 15:35:09 -0500 Subject: [PATCH 08/29] feat: update timestamp for iam_role_global & iam_role_org tables --- .../oss/postgres/100/01_iam_role_global.up.sql | 9 ++++++++- .../oss/postgres/100/02_iam_role_org.up.sql | 13 ++++++++++--- 2 files changed, 18 insertions(+), 4 deletions(-) diff --git a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql index c325d6545d..3b583d6f00 100644 --- a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql @@ -114,7 +114,14 @@ begin; ), constraint iam_role_global_grant_scope_fkey foreign key (role_id, grant_scope) - references iam_role_global(public_id, grant_scope) + references iam_role_global(public_id, grant_scope), + create_time wt_timestamp ); + create trigger default_create_time_column before insert on iam_role_global_individual_grant_scope + for each row execute procedure default_create_time(); + + create trigger immutable_columns before update on iam_role_global_individual_grant_scope + for each row execute procedure immutable_columns('scope_id', 'create_time'); + commit; \ No newline at end of file diff --git a/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql b/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql index 6944d88aef..236fa40bc4 100644 --- a/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql @@ -39,6 +39,7 @@ begin; on delete restrict on update cascade, version wt_version, + grant_this_role_scope_update_time wt_timestamp, grant_scope_update_time wt_timestamp, unique(public_id, grant_scope) ); @@ -49,6 +50,9 @@ begin; create trigger insert_iam_role_org_grant_scope_update_time before update on iam_role_org for each row execute procedure insert_grant_scope_update_time(); + create trigger insert_iam_role_org_grant_this_role_scope_update_time before update on iam_role_org + for each row execute procedure insert_grant_this_role_scope_update_time(); + create table iam_role_org_individual_grant_scope ( role_id wt_role_id constraint iam_role_org_fkey @@ -66,15 +70,19 @@ begin; grant_scope = 'individual' ), scope_id wt_scope_id - constraint iam_scope_org_fkey + constraint iam_scope_org_scope_id_fkey references iam_scope_project(scope_id) on delete cascade on update cascade, constraint iam_role_org_grant_scope_fkey foreign key (role_id, grant_scope) - references iam_role_org(public_id, grant_scope) + references iam_role_org(public_id, grant_scope), + create_time wt_timestamp ); + create trigger default_create_time_column before insert on iam_role_org_individual_grant_scope + for each row execute procedure default_create_time(); + -- ensure the project's parent is the role's scope create or replace function ensure_project_belongs_to_org() returns trigger as $$ @@ -112,7 +120,6 @@ begin; end; $$ language plpgsql; - create trigger ensure_project_belongs_to_org before insert or update on iam_role_org_individual_grant_scope for each row execute procedure ensure_project_belongs_to_org(); From 63c6b3a837af148136e78ef23b2f3701b078943d Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Tue, 28 Jan 2025 02:08:12 -0500 Subject: [PATCH 09/29] feat: update iam role timestamps --- .../postgres/100/01_iam_role_global.up.sql | 14 +++++--- .../oss/postgres/100/02_iam_role_org.up.sql | 10 ++++-- .../oss/postgres/100/04_resource.up.sql | 34 +++++++++---------- .../db/sqltest/tests/iam/iam_role_global.sql | 2 +- 4 files changed, 36 insertions(+), 24 deletions(-) diff --git a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql index 3b583d6f00..ff0f4f0409 100644 --- a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql @@ -35,7 +35,7 @@ begin; create or replace function insert_grant_scope_update_time() returns trigger as $$ begin - if (new.grant_scope != old.grant_scope) then + if new.grant_scope is distinct from old.grant_scope then new.grant_scope_update_time = now(); end if; return new; @@ -45,7 +45,7 @@ begin; create or replace function insert_grant_this_role_scope_update_time() returns trigger as $$ begin - if (new.grant_this_role_scope != old.grant_this_role_scope) then + if new.grant_this_role_scope is distinct from old.grant_this_role_scope then new.grant_scope_update_time = now(); end if; return new; @@ -81,10 +81,16 @@ begin; create trigger insert_role_subtype before insert on iam_role_global for each row execute procedure insert_role_subtype(); - create trigger insert_iam_role_global_grant_scope_update_time before update on iam_role_global + create trigger insert_grant_scope_update_time before insert on iam_role_global + for each row execute procedure insert_grant_scope_update_time(); + + create trigger insert_grant_this_role_scope_update_time before insert on iam_role_global + for each row execute procedure insert_grant_this_role_scope_update_time(); + + create trigger update_iam_role_global_grant_scope_update_time before update on iam_role_global for each row execute procedure insert_grant_scope_update_time(); - create trigger insert_iam_role_global_grant_this_role_scope_update_time before update on iam_role_global + create trigger update_iam_role_global_grant_this_role_scope_update_time before update on iam_role_global for each row execute procedure insert_grant_this_role_scope_update_time(); create table iam_role_global_individual_grant_scope ( diff --git a/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql b/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql index 236fa40bc4..1baaa78709 100644 --- a/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql @@ -47,10 +47,16 @@ begin; create trigger insert_role_subtype before insert on iam_role_org for each row execute procedure insert_role_subtype(); - create trigger insert_iam_role_org_grant_scope_update_time before update on iam_role_org + create trigger insert_iam_role_org_grant_scope_update_time before insert on iam_role_org for each row execute procedure insert_grant_scope_update_time(); - create trigger insert_iam_role_org_grant_this_role_scope_update_time before update on iam_role_org + create trigger insert_iam_role_org_grant_this_role_scope_update_time before insert on iam_role_org + for each row execute procedure insert_grant_this_role_scope_update_time(); + + create trigger update_iam_role_org_grant_scope_update_time before update on iam_role_org + for each row execute procedure insert_grant_scope_update_time(); + + create trigger update_iam_role_org_grant_this_role_scope_update_time before update on iam_role_org for each row execute procedure insert_grant_this_role_scope_update_time(); create table iam_role_org_individual_grant_scope ( diff --git a/internal/db/schema/migrations/oss/postgres/100/04_resource.up.sql b/internal/db/schema/migrations/oss/postgres/100/04_resource.up.sql index b4b28caf30..8514e5dfe2 100644 --- a/internal/db/schema/migrations/oss/postgres/100/04_resource.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/04_resource.up.sql @@ -10,29 +10,29 @@ begin; insert into resource_enm (string) values ('*'), - ('unknown'), - ('scope'), - ('user'), - ('group'), - ('role'), + ('alias'), ('auth-method'), - ('account'), ('auth-token'), + ('account'), + ('billing'), + ('controller'), + ('credential'), + ('credential-library'), + ('credential-store'), + ('group'), + ('host'), ('host-catalog'), ('host-set'), - ('host'), - ('target'), - ('controller'), - ('worker'), + ('managed-group'), + ('policy'), + ('role'), + ('scope'), ('session'), ('session-recording'), - ('managed-group'), - ('credential-store'), - ('credential-library'), - ('credential'), ('storage-bucket'), - ('policy'), - ('billing'), - ('alias'); + ('target'), + ('unknown'), + ('user'), + ('worker'); commit; \ No newline at end of file diff --git a/internal/db/sqltest/tests/iam/iam_role_global.sql b/internal/db/sqltest/tests/iam/iam_role_global.sql index a972bf7799..c0d874c733 100644 --- a/internal/db/sqltest/tests/iam/iam_role_global.sql +++ b/internal/db/sqltest/tests/iam/iam_role_global.sql @@ -81,7 +81,7 @@ begin; -- 2c) check if grant_scope_update_time is set select is( - (select grant_scope_update_time is null from iam_role_global where public_id = 'r_1111111111'), + (select grant_scope_update_time is not null from iam_role_global where public_id = 'r_1111111111'), true, 'grant_scope_update_time should be set with the default timestamp right after insert' ); From 9e5a1556682669d62349a1ecb0485d2cbd8212df Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Tue, 28 Jan 2025 10:59:35 -0500 Subject: [PATCH 10/29] chore: remove unapplicable comment --- .../schema/migrations/oss/postgres/100/05_iam_grant.up.sql | 5 ----- 1 file changed, 5 deletions(-) diff --git a/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql b/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql index 329dc64b8b..a45f0e14ac 100644 --- a/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql @@ -6,11 +6,6 @@ begin; -- iam_grant is the root table for a grant value object. -- A grant can only reference a single resource, including the special -- strings "*" to indicate "all" resources, and "unknown" when no resource is set. - -- The set of actions that are included in the grant - -- get associated with the grant in the iam_grant_action - -- table. We could potentially have a trigger function on insert - -- that parses the grant and inserts the appropriate rows into the other tables. - -- This should be immutable, and there isn't really a need to delete them. create table iam_grant ( canonical_grant text not null primary key, resource text not null From 14c6430ca44dd51044b74413cd780e29f68fc515 Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Tue, 28 Jan 2025 16:15:08 -0500 Subject: [PATCH 11/29] add timestamps on create or update to fields Co-authored-by: David Kanney Co-authored-by: Sorawis Nilparuk --- .../postgres/100/01_iam_role_global.up.sql | 34 +++++++++++++- .../oss/postgres/100/02_iam_role_org.up.sql | 17 +++++-- .../postgres/100/03_iam_role_project.up.sql | 16 ++++++- internal/db/sqltest/Makefile | 44 +++++++++---------- 4 files changed, 83 insertions(+), 28 deletions(-) diff --git a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql index ff0f4f0409..e5256d5275 100644 --- a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql @@ -52,6 +52,25 @@ begin; end; $$ language plpgsql; + -- Add trigger to update the new column on every iam_role subtype update. + -- This is used to update the update_time of the iam_role table + -- when either the name or the description of the subtype tables are updated. + -- This is only applicable to the name and description columns because we + -- do not want the update_time to be updated when the grant_scope or grant_this_role_scope + -- columns are updated. + create function update_iam_role_table_update_time() returns trigger + as $$ + begin + if (new.name is distinct from old.name) or (new.description is distinct from old.description) then + update iam_role set update_time = now() where public_id = new.public_id; + return new; + end if; + end; + $$ language plpgsql; + comment on function update_iam_role_table_update_time() is + 'update_iam_role_table_update_time is used to automatically update the update_time ' + 'of the base table whenever one of the subtype tables are updated'; + -- global iam_role must have a scope_id of global create table iam_role_global ( public_id wt_role_id not null primary key @@ -75,6 +94,8 @@ begin; version wt_version, grant_this_role_scope_update_time wt_timestamp, grant_scope_update_time wt_timestamp, + create_time wt_timestamp, + update_time wt_timestamp, unique(public_id, grant_scope) ); @@ -93,6 +114,15 @@ begin; create trigger update_iam_role_global_grant_this_role_scope_update_time before update on iam_role_global for each row execute procedure insert_grant_this_role_scope_update_time(); + create trigger default_create_time_column before insert on iam_role_global + for each row execute procedure default_create_time(); + + create trigger update_iam_role_table_update_time before update on iam_role_global + for each row execute procedure update_iam_role_table_update_time(); + + create trigger immutable_columns before update on iam_role_global + for each row execute procedure immutable_columns('scope_id', 'create_time'); + create table iam_role_global_individual_grant_scope ( role_id wt_role_id constraint iam_role_global_fkey @@ -125,9 +155,9 @@ begin; ); create trigger default_create_time_column before insert on iam_role_global_individual_grant_scope - for each row execute procedure default_create_time(); + for each row execute procedure default_create_time(); create trigger immutable_columns before update on iam_role_global_individual_grant_scope - for each row execute procedure immutable_columns('scope_id', 'create_time'); + for each row execute procedure immutable_columns('scope_id', 'create_time'); commit; \ No newline at end of file diff --git a/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql b/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql index 1baaa78709..0a1fafad7a 100644 --- a/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql @@ -41,6 +41,8 @@ begin; version wt_version, grant_this_role_scope_update_time wt_timestamp, grant_scope_update_time wt_timestamp, + create_time wt_timestamp, + updated_at wt_timestamp, unique(public_id, grant_scope) ); @@ -59,6 +61,15 @@ begin; create trigger update_iam_role_org_grant_this_role_scope_update_time before update on iam_role_org for each row execute procedure insert_grant_this_role_scope_update_time(); + create trigger default_create_time_column before insert on iam_role_org + for each row execute procedure default_create_time(); + + create trigger update_iam_role_table_update_time before update on iam_role_org + for each row execute procedure update_iam_role_table_update_time(); + + create trigger immutable_columns before update on iam_role_org + for each row execute procedure immutable_columns('scope_id', 'create_time'); + create table iam_role_org_individual_grant_scope ( role_id wt_role_id constraint iam_role_org_fkey @@ -90,7 +101,7 @@ begin; for each row execute procedure default_create_time(); -- ensure the project's parent is the role's scope - create or replace function ensure_project_belongs_to_org() returns trigger + create or replace function ensure_project_belongs_to_role_org() returns trigger as $$ declare org_scope_id text; @@ -126,7 +137,7 @@ begin; end; $$ language plpgsql; - create trigger ensure_project_belongs_to_org before insert or update on iam_role_org_individual_grant_scope - for each row execute procedure ensure_project_belongs_to_org(); + create trigger ensure_project_belongs_to_role_org before insert or update on iam_role_org_individual_grant_scope + for each row execute procedure ensure_project_belongs_to_role_org(); commit; \ No newline at end of file diff --git a/internal/db/schema/migrations/oss/postgres/100/03_iam_role_project.up.sql b/internal/db/schema/migrations/oss/postgres/100/03_iam_role_project.up.sql index 017a02b9e3..1734a0401e 100644 --- a/internal/db/schema/migrations/oss/postgres/100/03_iam_role_project.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/03_iam_role_project.up.sql @@ -16,7 +16,21 @@ begin; on update cascade, name text, description text, - version wt_version + version wt_version, + create_time wt_timestamp, + update_time wt_timestamp ); + create trigger update_iam_role_table_update_time before update on iam_role_global + for each row execute procedure update_iam_role_table_update_time(); + + create trigger default_create_time_column before insert on iam_role_project + for each row execute procedure default_create_time(); + + create trigger update_time_column before insert on iam_role_project + for each row execute procedure update_time_column(); + + create trigger immutable_columns before update on iam_role_project + for each row execute procedure immutable_columns('scope_id', 'create_time'); + commit; \ No newline at end of file diff --git a/internal/db/sqltest/Makefile b/internal/db/sqltest/Makefile index 9b4ae30d5d..75ed09b670 100644 --- a/internal/db/sqltest/Makefile +++ b/internal/db/sqltest/Makefile @@ -17,29 +17,29 @@ endif PROVE_OPTS ?= TESTS ?= tests/setup/*.sql \ - tests/account/*/*.sql \ - tests/alias/*.sql \ - tests/auth/*/*.sql \ - tests/census/*.sql \ - tests/controller/*.sql \ - tests/credential/*/*.sql \ - tests/domain/*.sql \ - tests/hcp/*/*.sql \ - tests/history/*.sql \ - tests/host/*.sql \ tests/iam/*.sql \ - tests/kms/*.sql \ - tests/org/*.sql \ - tests/pagination/*.sql \ - tests/policy/*.sql \ - tests/purge/*.sql \ - tests/recording/*.sql \ - tests/sentinel/*.sql \ - tests/server/*.sql \ - tests/session/*.sql \ - tests/storage/*.sql \ - tests/target/*.sql \ - tests/wh/*/*.sql \ + # tests/account/*/*.sql \ + # tests/alias/*.sql \ + # tests/auth/*/*.sql \ + # tests/census/*.sql \ + # tests/controller/*.sql \ + # tests/credential/*/*.sql \ + # tests/domain/*.sql \ + # tests/hcp/*/*.sql \ + # tests/history/*.sql \ + # tests/host/*.sql \ + # tests/kms/*.sql \ + # tests/org/*.sql \ + # tests/pagination/*.sql \ + # tests/policy/*.sql \ + # tests/purge/*.sql \ + # tests/recording/*.sql \ + # tests/sentinel/*.sql \ + # tests/server/*.sql \ + # tests/session/*.sql \ + # tests/storage/*.sql \ + # tests/target/*.sql \ + # tests/wh/*/*.sql \ POSTGRES_DOCKER_IMAGE_BASE ?= postgres From 021f3242689c389efcd2f3679b0b9a1638353a51 Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Tue, 28 Jan 2025 16:24:19 -0500 Subject: [PATCH 12/29] revert db/makefile change --- internal/db/sqltest/Makefile | 46 ++++++++++++++++++------------------ 1 file changed, 23 insertions(+), 23 deletions(-) diff --git a/internal/db/sqltest/Makefile b/internal/db/sqltest/Makefile index 75ed09b670..b85c76b996 100644 --- a/internal/db/sqltest/Makefile +++ b/internal/db/sqltest/Makefile @@ -17,29 +17,29 @@ endif PROVE_OPTS ?= TESTS ?= tests/setup/*.sql \ + tests/account/*/*.sql \ + tests/alias/*.sql \ + tests/auth/*/*.sql \ + tests/census/*.sql \ + tests/controller/*.sql \ + tests/credential/*/*.sql \ + tests/domain/*.sql \ + tests/hcp/*/*.sql \ + tests/history/*.sql \ + tests/host/*.sql \ tests/iam/*.sql \ - # tests/account/*/*.sql \ - # tests/alias/*.sql \ - # tests/auth/*/*.sql \ - # tests/census/*.sql \ - # tests/controller/*.sql \ - # tests/credential/*/*.sql \ - # tests/domain/*.sql \ - # tests/hcp/*/*.sql \ - # tests/history/*.sql \ - # tests/host/*.sql \ - # tests/kms/*.sql \ - # tests/org/*.sql \ - # tests/pagination/*.sql \ - # tests/policy/*.sql \ - # tests/purge/*.sql \ - # tests/recording/*.sql \ - # tests/sentinel/*.sql \ - # tests/server/*.sql \ - # tests/session/*.sql \ - # tests/storage/*.sql \ - # tests/target/*.sql \ - # tests/wh/*/*.sql \ + tests/kms/*.sql \ + tests/org/*.sql \ + tests/pagination/*.sql \ + tests/policy/*.sql \ + tests/purge/*.sql \ + tests/recording/*.sql \ + tests/sentinel/*.sql \ + tests/server/*.sql \ + tests/session/*.sql \ + tests/storage/*.sql \ + tests/target/*.sql \ + tests/wh/*/*.sql \ POSTGRES_DOCKER_IMAGE_BASE ?= postgres @@ -117,4 +117,4 @@ clean: docker stop $(SQL_TEST_CONTAINER_NAME) || true docker rm -v $(SQL_TEST_CONTAINER_NAME) || true -.PHONY: all clean test database-up run-tests +.PHONY: all clean test database-up run-tests \ No newline at end of file From 3cad65ed9ab4f58b700f2f70ddc3ad02c933ad04 Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Thu, 30 Jan 2025 05:35:18 -0500 Subject: [PATCH 13/29] Address PR feedback - alter iam_role_grant to add constraint on canonical_grant - add comments to all functions and tables - remove function for only setting `update_time` on iam_role subtypes when only the name and description have been updated - add new trigger for setting update_time when iam_role subtypes are updated - add new trigger for updating the version when iam_role subtypes are updated - update resource_enm table column name from `string` to `name` - add constraint to resource_enm table for `name` column --- .../migrations/oss/postgres/0/06_iam.up.sql | 1 + .../postgres/100/01_iam_role_global.up.sql | 75 +++++++++++-------- .../oss/postgres/100/02_iam_role_org.up.sql | 70 ++++++++--------- .../postgres/100/03_iam_role_project.up.sql | 12 +-- .../oss/postgres/100/04_resource.up.sql | 35 ++++++++- .../oss/postgres/100/05_iam_grant.up.sql | 18 ++++- .../oss/postgres/100/06_iam_role_grant.up.sql | 2 + .../db/sqltest/tests/iam/iam_role_org.sql | 2 - 8 files changed, 137 insertions(+), 78 deletions(-) delete mode 100644 internal/db/sqltest/tests/iam/iam_role_org.sql diff --git a/internal/db/schema/migrations/oss/postgres/0/06_iam.up.sql b/internal/db/schema/migrations/oss/postgres/0/06_iam.up.sql index 4f5816fd2e..254a44d736 100644 --- a/internal/db/schema/migrations/oss/postgres/0/06_iam.up.sql +++ b/internal/db/schema/migrations/oss/postgres/0/06_iam.up.sql @@ -332,6 +332,7 @@ create table iam_role ( ); -- Grants are immutable, which is enforced via the trigger below + -- Altered in 100/05_iam_grant.up.sql to add constraint on canonical_grant create table iam_role_grant ( create_time wt_timestamp, role_id wt_role_id -- pk diff --git a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql index e5256d5275..775d534ab7 100644 --- a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql @@ -3,8 +3,9 @@ begin; + -- Create the enumeration table for the grant scope types for the global iam_role create table iam_role_global_grant_scope_enm ( - name text not null primary key + name text primary key constraint only_predefined_scope_types_allowed check( name in ( @@ -14,14 +15,17 @@ begin; ) ) ); + comment on table iam_role_global_grant_scope_enm is + 'iam_role_global_grant_scope_enm is an enumeration table for role grant scope types for for the iam_role_global table.'; + -- Insert the predefined grant scope types for iam_role_global insert into iam_role_global_grant_scope_enm (name) values ('descendants'), ('children'), ('individual'); - create or replace function insert_role_subtype() returns trigger + create function insert_role_subtype() returns trigger as $$ begin insert into iam_role @@ -31,8 +35,11 @@ begin; return new; end; $$ language plpgsql; + comment on function insert_role_subtype() is + 'insert_role_subtype is used to automatically insert a row into the iam_role table ' + 'whenever a row is inserted into the subtype table'; - create or replace function insert_grant_scope_update_time() returns trigger + create function insert_grant_scope_update_time() returns trigger as $$ begin if new.grant_scope is distinct from old.grant_scope then @@ -41,44 +48,40 @@ begin; return new; end; $$ language plpgsql; + comment on function insert_grant_scope_update_time() is + 'insert_grant_scope_update_time is used to automatically update the grant_scope_update_time ' + 'of the subtype table whenever the grant_scope column is updated'; - create or replace function insert_grant_this_role_scope_update_time() returns trigger + create function insert_grant_this_role_scope_update_time() returns trigger as $$ begin if new.grant_this_role_scope is distinct from old.grant_this_role_scope then - new.grant_scope_update_time = now(); + new.grant_this_role_scope_update_time = now(); end if; return new; end; $$ language plpgsql; - - -- Add trigger to update the new column on every iam_role subtype update. - -- This is used to update the update_time of the iam_role table - -- when either the name or the description of the subtype tables are updated. - -- This is only applicable to the name and description columns because we - -- do not want the update_time to be updated when the grant_scope or grant_this_role_scope - -- columns are updated. - create function update_iam_role_table_update_time() returns trigger - as $$ - begin - if (new.name is distinct from old.name) or (new.description is distinct from old.description) then - update iam_role set update_time = now() where public_id = new.public_id; - return new; - end if; - end; - $$ language plpgsql; - comment on function update_iam_role_table_update_time() is - 'update_iam_role_table_update_time is used to automatically update the update_time ' - 'of the base table whenever one of the subtype tables are updated'; - - -- global iam_role must have a scope_id of global + comment on function insert_grant_this_role_scope_update_time() is + 'insert_grant_this_role_scope_update_time is used to automatically update the grant_scope_update_time ' + 'of the subtype table whenever the grant_this_role_scope column is updated'; + + -- global iam_role must have a scope_id of global. + -- + -- grant_this_role_scope indicates if the role can apply its grants to the scope. + -- grant_scope indicates the scope of the grants. + -- grant_scope can be 'descendants', 'children', or 'individual'. + -- + -- grant_this_role_scope_update_time and grant_scope_update_time are used to track + -- the last time the grant_this_role_scope and grant_scope columns were updated. + -- This is used to represent the grant scope create_time column from the + -- iam_role_grant_scope table in 83/01_iam_role_grant_scope.up.sql. create table iam_role_global ( public_id wt_role_id not null primary key constraint iam_role_fkey references iam_role(public_id) on delete cascade on update cascade, - scope_id wt_scope_id + scope_id wt_scope_id not null constraint iam_scope_global_fkey references iam_scope_global(scope_id) on delete cascade @@ -98,6 +101,11 @@ begin; update_time wt_timestamp, unique(public_id, grant_scope) ); + comment on table iam_role_global is + 'iam_role_global is the subtype table for the global role. ' + + 'grant_this_role_scope_update_time and grant_scope_update_time ' + + 'are used to track the last time the grant_this_role_scope and ' + + 'grant_scope columns were updated.'; create trigger insert_role_subtype before insert on iam_role_global for each row execute procedure insert_role_subtype(); @@ -117,8 +125,11 @@ begin; create trigger default_create_time_column before insert on iam_role_global for each row execute procedure default_create_time(); - create trigger update_iam_role_table_update_time before update on iam_role_global - for each row execute procedure update_iam_role_table_update_time(); + create trigger update_time_column before update on iam_role_global + for each row execute procedure update_time_column(); + + create trigger update_version_column after update on iam_role_global + for each row execute procedure update_version_column(); create trigger immutable_columns before update on iam_role_global for each row execute procedure immutable_columns('scope_id', 'create_time'); @@ -139,7 +150,7 @@ begin; check( grant_scope = 'individual' ), - scope_id wt_scope_id + scope_id wt_scope_id not null constraint iam_scope_fkey references iam_scope(public_id) on delete cascade @@ -153,11 +164,13 @@ begin; references iam_role_global(public_id, grant_scope), create_time wt_timestamp ); + comment on table iam_role_global_individual_grant_scope is + 'iam_role_global_individual_grant_scope is the subtype table for the global role with grant_scope as individual.'; create trigger default_create_time_column before insert on iam_role_global_individual_grant_scope for each row execute procedure default_create_time(); create trigger immutable_columns before update on iam_role_global_individual_grant_scope - for each row execute procedure immutable_columns('scope_id', 'create_time'); + for each row execute procedure immutable_columns('role_id', 'grant_scope', 'scope_id', 'create_time'); commit; \ No newline at end of file diff --git a/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql b/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql index 0a1fafad7a..36af6a2f85 100644 --- a/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql @@ -2,7 +2,8 @@ -- SPDX-License-Identifier: BUSL-1.1 begin; - + + -- Create the enumeration table for the grant scope types for the org iam_role create table iam_role_org_grant_scope_enm ( name text not null primary key constraint only_predefined_scope_types_allowed @@ -13,19 +14,22 @@ begin; ) ) ); + comment on table iam_role_org_grant_scope_enm is + 'iam_role_org_grant_scope_enm is an enumeration table for role grant scope types for the iam_role_org table.'; + -- Insert the predefined grant scope types for iam_role_org insert into iam_role_org_grant_scope_enm (name) values ('children'), ('individual'); create table iam_role_org ( - public_id wt_role_id not null primary key + public_id wt_role_id primary key constraint iam_role_fkey references iam_role(public_id) on delete cascade on update cascade, - scope_id wt_scope_id + scope_id wt_scope_id not null constraint iam_scope_org_fkey references iam_scope_org(scope_id) on delete cascade @@ -45,6 +49,8 @@ begin; updated_at wt_timestamp, unique(public_id, grant_scope) ); + comment on table iam_role_org is + 'iam_role_org is a subtype table of the iam_role table. It is used to store roles that are scoped to an org.'; create trigger insert_role_subtype before insert on iam_role_org for each row execute procedure insert_role_subtype(); @@ -64,8 +70,11 @@ begin; create trigger default_create_time_column before insert on iam_role_org for each row execute procedure default_create_time(); - create trigger update_iam_role_table_update_time before update on iam_role_org - for each row execute procedure update_iam_role_table_update_time(); + create trigger update_time_column before update on iam_role_org + for each row execute procedure update_time_column(); + + create trigger update_version_column after update on iam_role_org + for each row execute procedure update_version_column(); create trigger immutable_columns before update on iam_role_org for each row execute procedure immutable_columns('scope_id', 'create_time'); @@ -86,7 +95,7 @@ begin; check( grant_scope = 'individual' ), - scope_id wt_scope_id + scope_id wt_scope_id not null constraint iam_scope_org_scope_id_fkey references iam_scope_project(scope_id) on delete cascade @@ -96,46 +105,33 @@ begin; references iam_role_org(public_id, grant_scope), create_time wt_timestamp ); + comment on table iam_role_org_individual_grant_scope is + 'iam_role_global_individual_grant_scope is the subtype table for the org role with grant_scope as individual.'; create trigger default_create_time_column before insert on iam_role_org_individual_grant_scope - for each row execute procedure default_create_time(); + for each row execute procedure default_create_time(); + + create trigger immutable_columns before update on iam_role_org_individual_grant_scope + for each row execute procedure immutable_columns('role_id', 'grant_scope', 'scope_id', 'create_time'); -- ensure the project's parent is the role's scope - create or replace function ensure_project_belongs_to_role_org() returns trigger + create function ensure_project_belongs_to_role_org() returns trigger as $$ declare - org_scope_id text; - project_parent_id text; - begin - -- Find the org scope for this role - select scope_id - into org_scope_id - from iam_role_org - where public_id = new.role_id; - - if org_scope_id is null then - raise exception 'role % not found in iam_role_org', new.role_id; - end if; - - -- Find the project parent for the inserted scope_id - select parent_id - into project_parent_id - from iam_scope_project - where scope_id = new.scope_id; - - if project_parent_id is null then - raise exception 'project scope_id % not found in iam_scope_project', new.scope_id; - end if; - - -- Compare parent_id with the org scope - if project_parent_id != org_scope_id then - raise exception 'project % belongs to a different org', - new.scope_id; - end if; - + perform + from iam_scope_project + join iam_role_org + on iam_role_org.scope_id = iam_scope_project.parent_id + where iam_scope_project.scope_id = new.scope_id + and iam_role_org.public_id = new.role_id; + if not found then + raise exception 'project scope_id % not found in org', new.scope_id; + end if; return new; end; $$ language plpgsql; + comment on function ensure_project_belongs_to_role_org() is + 'ensure_project_belongs_to_role_org ensures the project belongs to the org of the role.'; create trigger ensure_project_belongs_to_role_org before insert or update on iam_role_org_individual_grant_scope for each row execute procedure ensure_project_belongs_to_role_org(); diff --git a/internal/db/schema/migrations/oss/postgres/100/03_iam_role_project.up.sql b/internal/db/schema/migrations/oss/postgres/100/03_iam_role_project.up.sql index 1734a0401e..548c1bf58a 100644 --- a/internal/db/schema/migrations/oss/postgres/100/03_iam_role_project.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/03_iam_role_project.up.sql @@ -4,7 +4,7 @@ begin; create table iam_role_project ( - public_id wt_role_id not null primary key + public_id wt_role_id primary key constraint iam_role_fkey references iam_role(public_id) on delete cascade @@ -20,16 +20,18 @@ begin; create_time wt_timestamp, update_time wt_timestamp ); - - create trigger update_iam_role_table_update_time before update on iam_role_global - for each row execute procedure update_iam_role_table_update_time(); + comment on table iam_role_project is + 'iam_role_project is a subtype table of the iam_role table. It is used to store roles that are scoped to a project.'; create trigger default_create_time_column before insert on iam_role_project for each row execute procedure default_create_time(); - create trigger update_time_column before insert on iam_role_project + create trigger update_time_column before update on iam_role_project for each row execute procedure update_time_column(); + create trigger update_version_column after update on iam_role_project + for each row execute procedure update_version_column(); + create trigger immutable_columns before update on iam_role_project for each row execute procedure immutable_columns('scope_id', 'create_time'); diff --git a/internal/db/schema/migrations/oss/postgres/100/04_resource.up.sql b/internal/db/schema/migrations/oss/postgres/100/04_resource.up.sql index 8514e5dfe2..86454dde06 100644 --- a/internal/db/schema/migrations/oss/postgres/100/04_resource.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/04_resource.up.sql @@ -4,9 +4,42 @@ begin; create table resource_enm ( - string text not null primary key + name text primary key + constraint only_predefined_resource_types_allowed + check( + name in ( + '*', + 'alias', + 'auth-method', + 'auth-token', + 'account', + 'billing', + 'controller', + 'credential', + 'credential-library', + 'credential-store', + 'group', + 'host', + 'host-catalog', + 'host-set', + 'managed-group', + 'policy', + 'role', + 'scope', + 'session', + 'session-recording', + 'storage-bucket', + 'target', + 'unknown', + 'user', + 'worker' + ) + ) ); + comment on table resource_enm is + 'resource_enm is an enumeration table for resource types.'; + -- Insert the predefined resource types insert into resource_enm (string) values ('*'), diff --git a/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql b/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql index a45f0e14ac..c1f3fa737e 100644 --- a/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql @@ -7,13 +7,16 @@ begin; -- A grant can only reference a single resource, including the special -- strings "*" to indicate "all" resources, and "unknown" when no resource is set. create table iam_grant ( - canonical_grant text not null primary key, + canonical_grant text primary key, resource text not null constraint resource_enm_fkey - references resource_enm(string) + references resource_enm(name) on delete restrict on update cascade ); + comment on table iam_grant is + 'iam_grant is the root table for a grant value object. A grant can only reference a single resource, ' + + 'including the special strings "*" to indicate "all" resources, and "unknown" when no resource is set.'; create index iam_grant_resource_ix on iam_grant (resource); @@ -32,8 +35,19 @@ begin; return new; end $$ language plpgsql; + comment on function set_resource() is + 'set_resource is a trigger function that sets the resource column based on the canonical_grant.'; create trigger set_resource before insert on iam_grant for each row execute procedure set_resource(); + -- Add a foreign key constraint to the iam_role_grant table to ensure that the canonical_grant exists in the iam_grant table. + -- Alter to add foreign key constraint to the iam_role_grant table defined in 01/06_iam.up.sql + alter table iam_role_grant + add constraint iam_grant_fkey + foreign key (canonical_grant) + references iam_grant(canonical_grant) + on delete cascade + on update cascade; + commit; \ No newline at end of file diff --git a/internal/db/schema/migrations/oss/postgres/100/06_iam_role_grant.up.sql b/internal/db/schema/migrations/oss/postgres/100/06_iam_role_grant.up.sql index 80f1df50a2..daba8684dc 100644 --- a/internal/db/schema/migrations/oss/postgres/100/06_iam_role_grant.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/06_iam_role_grant.up.sql @@ -17,6 +17,8 @@ begin; return new; end $$ language plpgsql; + comment on function upsert_canonical_grant() is + 'upsert_canonical_grant is a trigger function that inserts a row into the iam_grant table if the canonical_grant does not exist.'; create trigger upsert_canonical_grant before insert on iam_role_grant for each row execute procedure upsert_canonical_grant(); diff --git a/internal/db/sqltest/tests/iam/iam_role_org.sql b/internal/db/sqltest/tests/iam/iam_role_org.sql deleted file mode 100644 index 44bac043bb..0000000000 --- a/internal/db/sqltest/tests/iam/iam_role_org.sql +++ /dev/null @@ -1,2 +0,0 @@ --- Copyright (c) HashiCorp, Inc. --- SPDX-License-Identifier: BUSL-1.1 \ No newline at end of file From 014c09cc358a7b7e85002c6e640212d050bea6c8 Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Fri, 31 Jan 2025 21:37:49 -0500 Subject: [PATCH 14/29] - fix comments - update update_time column on iam_role_org - update syntax error on `ensure_project_belongs_to_role_org` function - adding missing subtype trigger on iam_role_project - fix column insert on `resource_enm` --- .../migrations/oss/postgres/100/01_iam_role_global.up.sql | 5 +---- .../migrations/oss/postgres/100/02_iam_role_org.up.sql | 8 ++++---- .../oss/postgres/100/03_iam_role_project.up.sql | 3 +++ .../schema/migrations/oss/postgres/100/04_resource.up.sql | 2 +- .../migrations/oss/postgres/100/05_iam_grant.up.sql | 3 +-- 5 files changed, 10 insertions(+), 11 deletions(-) diff --git a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql index 775d534ab7..ef3c72ef8c 100644 --- a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql @@ -102,10 +102,7 @@ begin; unique(public_id, grant_scope) ); comment on table iam_role_global is - 'iam_role_global is the subtype table for the global role. ' + - 'grant_this_role_scope_update_time and grant_scope_update_time ' + - 'are used to track the last time the grant_this_role_scope and ' + - 'grant_scope columns were updated.'; + 'iam_role_global is the subtype table for the global role. grant_this_role_scope_update_time and grant_scope_update_time are used to track the last time the grant_this_role_scope and grant_scope columns were updated.'; create trigger insert_role_subtype before insert on iam_role_global for each row execute procedure insert_role_subtype(); diff --git a/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql b/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql index 36af6a2f85..54f5abc077 100644 --- a/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql @@ -36,7 +36,7 @@ begin; on update cascade, name text, description text, - grant_this_role_scope boolean not null, + grant_this_role_scope boolean not null default false, grant_scope text constraint iam_role_org_grant_scope_enm_fkey references iam_role_org_grant_scope_enm(name) @@ -46,7 +46,7 @@ begin; grant_this_role_scope_update_time wt_timestamp, grant_scope_update_time wt_timestamp, create_time wt_timestamp, - updated_at wt_timestamp, + update_time wt_timestamp, unique(public_id, grant_scope) ); comment on table iam_role_org is @@ -117,8 +117,8 @@ begin; -- ensure the project's parent is the role's scope create function ensure_project_belongs_to_role_org() returns trigger as $$ - declare - perform + begin + perform from iam_scope_project join iam_role_org on iam_role_org.scope_id = iam_scope_project.parent_id diff --git a/internal/db/schema/migrations/oss/postgres/100/03_iam_role_project.up.sql b/internal/db/schema/migrations/oss/postgres/100/03_iam_role_project.up.sql index 548c1bf58a..7170a96a47 100644 --- a/internal/db/schema/migrations/oss/postgres/100/03_iam_role_project.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/03_iam_role_project.up.sql @@ -23,6 +23,9 @@ begin; comment on table iam_role_project is 'iam_role_project is a subtype table of the iam_role table. It is used to store roles that are scoped to a project.'; + create trigger insert_role_subtype before insert on iam_role_project + for each row execute procedure insert_role_subtype(); + create trigger default_create_time_column before insert on iam_role_project for each row execute procedure default_create_time(); diff --git a/internal/db/schema/migrations/oss/postgres/100/04_resource.up.sql b/internal/db/schema/migrations/oss/postgres/100/04_resource.up.sql index 86454dde06..46e0cb9ede 100644 --- a/internal/db/schema/migrations/oss/postgres/100/04_resource.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/04_resource.up.sql @@ -40,7 +40,7 @@ begin; 'resource_enm is an enumeration table for resource types.'; -- Insert the predefined resource types - insert into resource_enm (string) + insert into resource_enm (name) values ('*'), ('alias'), diff --git a/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql b/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql index c1f3fa737e..6b5c7883ec 100644 --- a/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql @@ -15,8 +15,7 @@ begin; on update cascade ); comment on table iam_grant is - 'iam_grant is the root table for a grant value object. A grant can only reference a single resource, ' + - 'including the special strings "*" to indicate "all" resources, and "unknown" when no resource is set.'; + 'iam_grant is the root table for a grant value object. A grant can only reference a single resource, including the special strings "*" to indicate "all" resources, and "unknown" when no resource is set.'; create index iam_grant_resource_ix on iam_grant (resource); From 7a7c0dffa1e4c49c8a59e2013c14cff6a48cf5f2 Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Fri, 31 Jan 2025 21:39:09 -0500 Subject: [PATCH 15/29] add test coverage for new migration files --- .../db/sqltest/initdb.d/01_colors_persona.sql | 24 +-- internal/db/sqltest/initdb.d/02_wtt_load.sql | 6 - .../sqltest/initdb.d/03_widgets_persona.sql | 24 +-- internal/db/sqltest/tests/iam/iam_grant.sql | 87 +++++++++ .../db/sqltest/tests/iam/iam_role_global.sql | 37 ++-- .../db/sqltest/tests/iam/iam_role_org.sql | 171 ++++++++++++++++++ .../db/sqltest/tests/iam/iam_role_project.sql | 94 ++++++++++ 7 files changed, 387 insertions(+), 56 deletions(-) create mode 100644 internal/db/sqltest/tests/iam/iam_grant.sql create mode 100644 internal/db/sqltest/tests/iam/iam_role_org.sql create mode 100644 internal/db/sqltest/tests/iam/iam_role_project.sql diff --git a/internal/db/sqltest/initdb.d/01_colors_persona.sql b/internal/db/sqltest/initdb.d/01_colors_persona.sql index f918664a82..9ce83de931 100644 --- a/internal/db/sqltest/initdb.d/01_colors_persona.sql +++ b/internal/db/sqltest/initdb.d/01_colors_persona.sql @@ -32,12 +32,6 @@ -- optional or non-standard columns. begin; - -- setup resource for iam_grant - insert into resource_enm - (string) - values - ('color'); - -- Add organizations insert into iam_scope (parent_id, type, public_id, name) @@ -145,15 +139,15 @@ begin; values ('r_gg_____buy', 'type=*;action=purchase', 'purchase anything'), ('r_gg____shop', 'type=*;action=view', 'view anything'), - ('r_go____name', 'type=color;action=name', 'name colors'), - ('r_gp____spec', 'type=color;action=inspect', 'inspect colors'), - ('r_oo_____art', 'type=color;action=create', 'create color'), - ('r_op_bc__art', 'type=color;action=create', 'create color'), - ('r_op_rc__art', 'type=color;action=create', 'create color'), - ('r_op_gc__art', 'type=color;action=create', 'create color'), - ('r_pp_bc__mix', 'type=color;action=mix', 'mix color'), - ('r_pp_rc__mix', 'type=color;action=mix', 'mix color'), - ('r_pp_gc__mix', 'type=color;action=mix', 'mix color'); + ('r_go____name', 'type=group;action=name', 'name colors'), + ('r_gp____spec', 'type=group;action=inspect', 'inspect colors'), + ('r_oo_____art', 'type=group;action=create', 'create color'), + ('r_op_bc__art', 'type=group;action=create', 'create color'), + ('r_op_rc__art', 'type=group;action=create', 'create color'), + ('r_op_gc__art', 'type=group;action=create', 'create color'), + ('r_pp_bc__mix', 'type=group;action=mix', 'mix color'), + ('r_pp_rc__mix', 'type=group;action=mix', 'mix color'), + ('r_pp_gc__mix', 'type=group;action=mix', 'mix color'); insert into iam_group_role (role_id, principal_id) diff --git a/internal/db/sqltest/initdb.d/02_wtt_load.sql b/internal/db/sqltest/initdb.d/02_wtt_load.sql index 62e76ee238..a64790254a 100644 --- a/internal/db/sqltest/initdb.d/02_wtt_load.sql +++ b/internal/db/sqltest/initdb.d/02_wtt_load.sql @@ -2,12 +2,6 @@ -- SPDX-License-Identifier: BUSL-1.1 begin; - -- setup resource for iam_grant - insert into resource_enm - (string) - values - ('widget'); - -- wtt_load populates tables for the given test persona and set of aggregates. -- Valid personas are: -- * widgets diff --git a/internal/db/sqltest/initdb.d/03_widgets_persona.sql b/internal/db/sqltest/initdb.d/03_widgets_persona.sql index 8303e442e8..5193028bf7 100644 --- a/internal/db/sqltest/initdb.d/03_widgets_persona.sql +++ b/internal/db/sqltest/initdb.d/03_widgets_persona.sql @@ -54,16 +54,18 @@ begin; ('g___wb-group', 'u_____warren'), ('g___ws-group', 'u_____waylon'); - insert into iam_role + insert into iam_role_org (scope_id, public_id, name) values - -- ('global', 'r_gg_____buy', 'Purchaser'), - -- ('global', 'r_gg____shop', 'Shopper'), - ('p____bwidget', 'r_pp_bw__bld', 'Widget Builder'), - ('p____swidget', 'r_pp_sw__bld', 'Widget Builder'), ('o_____widget', 'r_op_sw__eng', 'Small Widget Engineer'), ('o_____widget', 'r_oo_____eng', 'Widget Engineer'); + insert into iam_role_project + (scope_id, public_id, name) + values + ('p____bwidget', 'r_pp_bw__bld', 'Widget Builder'), + ('p____swidget', 'r_pp_sw__bld', 'Widget Builder'); + insert into iam_role_grant_scope (role_id, scope_id_or_special) values @@ -77,12 +79,12 @@ begin; values -- ('r_gg_____buy', 'type=*;action=purchase', 'purchase anything'), -- ('r_gg____shop', 'type=*;action=view', 'view anything'), - ('r_oo_____eng', 'type=widget;action=design', 'design widget'), - ('r_op_sw__eng', 'type=widget;action=design', 'design widget'), - ('r_op_sw__eng', 'type=widget;action=tune', 'tune widget'), - ('r_op_sw__eng', 'type=widget;action=clean', 'clean widget'), - ('r_pp_bw__bld', 'type=widget;action=build', 'build widget'), - ('r_pp_sw__bld', 'type=widget;action=build', 'build widget'); + ('r_oo_____eng', 'type=target;action=design', 'design widget'), + ('r_op_sw__eng', 'type=target;action=design', 'design widget'), + ('r_op_sw__eng', 'type=target;action=tune', 'tune widget'), + ('r_op_sw__eng', 'type=target;action=clean', 'clean widget'), + ('r_pp_bw__bld', 'type=target;action=build', 'build widget'), + ('r_pp_sw__bld', 'type=target;action=build', 'build widget'); insert into iam_group_role (role_id, principal_id) diff --git a/internal/db/sqltest/tests/iam/iam_grant.sql b/internal/db/sqltest/tests/iam/iam_grant.sql new file mode 100644 index 0000000000..34d8957d4e --- /dev/null +++ b/internal/db/sqltest/tests/iam/iam_grant.sql @@ -0,0 +1,87 @@ +-- copyright (c) hashicorp, inc. +-- spdx-license-identifier: busl-1.1 + +begin; +select plan(9); +select wtt_load('widgets', 'iam'); + +prepare insert_grant_scope as + insert into iam_grant + (canonical_grant) + values + ('type=scope;others=stuff;'); + +select lives_ok('insert_grant_scope'); + +select is( + (select resource + from iam_grant + where canonical_grant = 'type=scope;others=stuff;'), + 'scope', + 'resource should be set to "scope" by set_resource() trigger' +); + +prepare insert_grant_no_type as + insert into iam_grant + (canonical_grant) + values + ('no_type_at_all;'); + +select lives_ok('insert_grant_no_type'); + +select is( + (select resource + from iam_grant + where canonical_grant = 'no_type_at_all;'), + 'unknown', + 'resource should default to "unknown" if type=... is not found' +); + +prepare insert_grant_role as + insert into iam_grant + (canonical_grant) + values + ('type=role;foo=bar;'); +select lives_ok('insert_grant_role'); + +select is( + (select resource + from iam_grant + where canonical_grant = 'type=role;foo=bar;'), + 'role', + 'resource should be set to "role"' +); + +-- the set_resource() trigger will set resource='bogus', but we did not insert 'bogus' +-- into resource_enm, so it should fail. +prepare insert_grant_bogus as + insert into iam_grant + (canonical_grant) + values + ('type=bogus;some=thing;'); +select throws_like( + 'insert_grant_bogus', + 'insert or update on table "iam_grant" violates foreign key constraint "resource_enm_fkey"', + 'inserting a resource not in resource_enm should fail' +); + +prepare insert_dup_grant_1 as + insert into iam_grant + (canonical_grant) + values + ('duplicate_grant;type=scope;'); +select lives_ok('insert_dup_grant_1'); + +prepare insert_dup_grant_2 as + insert into iam_grant + (canonical_grant) + values + ('duplicate_grant;type=scope;'); +select throws_like( + 'insert_dup_grant_2', + 'duplicate key value violates unique constraint "iam_grant_pkey"', + 'primary key (canonical_grant) is enforced' +); + +select * from finish(); +rollback; diff --git a/internal/db/sqltest/tests/iam/iam_role_global.sql b/internal/db/sqltest/tests/iam/iam_role_global.sql index c0d874c733..9445265caa 100644 --- a/internal/db/sqltest/tests/iam/iam_role_global.sql +++ b/internal/db/sqltest/tests/iam/iam_role_global.sql @@ -3,15 +3,7 @@ begin; select plan(14); - - -- Set up a scope to test against - insert into iam_scope - (type, public_id, parent_id) - values - ('org', 'o_1111111111', 'global'); - - -- remove any existing roles and their grant scopes, so we can test fresh - delete from iam_role; + select wtt_load('widgets', 'iam'); -------------------------------------------------------------------------------- -- 1) testing iam_role_global table constraints and insert_role_subtype @@ -28,7 +20,7 @@ begin; -- verify it also created a row in base iam_role select is(count(*), 1::bigint) from iam_role where public_id = 'r_1111111111'; - -- 1e) try duplicate (public_id, grant_scope) => unique violation + -- 1b) try duplicate (public_id, grant_scope) => unique violation prepare insert_dup_public_id_grant_scope as insert into iam_role_global (public_id, scope_id, grant_this_role_scope, grant_scope) @@ -40,7 +32,7 @@ begin; 'unique(public_id) is enforced' ); - -- 1b) invalid grant_scope (not in iam_role_global_grant_scope_enm table) + -- 1c) invalid grant_scope (not in iam_role_global_grant_scope_enm table) prepare insert_invalid_grant_scope as insert into iam_role_global (public_id, scope_id, grant_this_role_scope, grant_scope) @@ -52,7 +44,7 @@ begin; 'invalid grant_scope must fail foreign key to iam_role_global_grant_scope_enm' ); - -- 1c) invalid scope_id -> must reference iam_scope_global(scope_id) + -- 1d) invalid scope_id -> must reference iam_scope_global(scope_id) prepare insert_bad_scope_id as insert into iam_role_global (public_id, scope_id, grant_this_role_scope, grant_scope) @@ -68,20 +60,17 @@ begin; -- 2) testing insert_grant_scope_update_time trigger -------------------------------------------------------------------------------- - -- 2a) clean up any previous data - delete from iam_role; - -- 2b) insert a new row (grant_this_role_scope, grant_scope) => should initialize prepare insert_with_grant_scope_update_time_set as insert into iam_role_global - (public_id, scope_id, grant_this_role_scope, grant_scope, grant_scope_update_time) + (public_id, scope_id, grant_scope, grant_scope_update_time) values - ('r_1111111111', 'global', false, 'descendants', null); + ('r_2222222222', 'global', 'descendants', null); select lives_ok('insert_with_grant_scope_update_time_set'); -- 2c) check if grant_scope_update_time is set select is( - (select grant_scope_update_time is not null from iam_role_global where public_id = 'r_1111111111'), + (select grant_scope_update_time is not null from iam_role_global where public_id = 'r_2222222222'), true, 'grant_scope_update_time should be set with the default timestamp right after insert' ); @@ -90,10 +79,10 @@ begin; prepare update_grant_this_role_scope as update iam_role_global set grant_this_role_scope = true - where public_id = 'r_1111111111'; + where public_id = 'r_2222222222'; select lives_ok('update_grant_this_role_scope'); select is( - (select grant_scope_update_time is not null from iam_role_global where public_id = 'r_1111111111'), + (select grant_scope_update_time is not null from iam_role_global where public_id = 'r_2222222222'), true, 'grant_scope_update_time should be set with the default timestamp right after insert' ); @@ -107,7 +96,7 @@ begin; insert into iam_role_global_individual_grant_scope (role_id, scope_id, grant_scope) values - ('r_2111111111', 'descendants', 'global'); + ('r_3333333333', 'descendants', 'global'); select throws_like( 'insert_invalid_individual_grant_scope', 'new row for relation "iam_role_global_individual_grant_scope" violates check constraint "only_individual_grant_scope_allowed"', @@ -122,7 +111,7 @@ begin; ('r_1111111111', 'individual', 'o_1111111111'); select throws_like( 'insert_invalid_iam_role_global_individual_grant_scope', - 'insert or update on table "iam_role_global_individual_grant_scope" violates foreign key constraint "iam_role_global_grant_scope_fkey"', + 'insert or update on table "iam_role_global_individual_grant_scope" violates foreign key constraint "iam_scope_fkey"', 'foreign key also enforces matching grant_scope=individual in iam_role_global' ); @@ -143,14 +132,14 @@ begin; insert into iam_role_global (public_id, scope_id, grant_scope) values - ('r_3111111111', 'global', 'individual'); + ('r_3333333333', 'global', 'individual'); select lives_ok('insert_global_role_for_individual_scope'); prepare insert_valid_individual_org_scope as insert into iam_role_global_individual_grant_scope (role_id, grant_scope, scope_id) values - ('r_3111111111', 'individual', 'o_1111111111'); + ('r_3333333333', 'individual', 'o_____widget'); select lives_ok('insert_valid_individual_org_scope'); select * from finish(); diff --git a/internal/db/sqltest/tests/iam/iam_role_org.sql b/internal/db/sqltest/tests/iam/iam_role_org.sql new file mode 100644 index 0000000000..09d223aab3 --- /dev/null +++ b/internal/db/sqltest/tests/iam/iam_role_org.sql @@ -0,0 +1,171 @@ +-- Copyright (c) HashiCorp, Inc. +-- SPDX-License-Identifier: BUSL-1.1 + +begin; + select plan(16); + select wtt_load('widgets', 'iam'); + + ------------------------------------------------------------------------------ + -- 1) testing iam_role_org table constraints and insert_role_subtype + ------------------------------------------------------------------------------ + + -- 1a) insert a valid row -> should succeed and fire insert_role_subtype trigger + prepare insert_valid_org_role as + insert into iam_role_org + (public_id, scope_id, grant_this_role_scope, grant_scope) + values + ('r_org_1111111111', + 'o_____widget', + true, + 'children' + ); + + select lives_ok('insert_valid_org_role'); + + -- verify it also created a row in base iam_role + select is( + (select count(*) from iam_role where public_id = 'r_org_1111111111'), + 1::bigint, + 'insert_role_subtype trigger inserted a row into iam_role' + ); + + -- 1b) try duplicate (public_id, grant_scope) => unique violation + prepare insert_dup_public_id_grant_scope as + insert into iam_role_org + (public_id, scope_id, grant_this_role_scope, grant_scope) + values + ('r_org_1111111111', 'o_____widget', true, 'children'); + select throws_like( + 'insert_dup_public_id_grant_scope', + 'duplicate key value violates unique constraint "iam_role_pkey"', + 'unique(public_id, grant_scope) is enforced on iam_role_org' + ); + + -- 1c) invalid grant_scope (not in iam_role_org_grant_scope_enm) + prepare insert_invalid_grant_scope as + insert into iam_role_org + (public_id, scope_id, grant_this_role_scope, grant_scope) + values + ('r_org_bad_grscope', 'o_____widget', true, 'invalid_scope'); + select throws_like( + 'insert_invalid_grant_scope', + 'insert or update on table "iam_role_org" violates foreign key constraint "iam_role_org_grant_scope_enm_fkey"', + 'invalid grant_scope must fail foreign key to iam_role_org_grant_scope_enm' + ); + + -- 1d) invalid scope_id -> must reference iam_scope_org(scope_id) + prepare insert_bad_scope_id as + insert into iam_role_org + (public_id, scope_id, grant_this_role_scope, grant_scope) + values + ('r_org_bad_scope', 'x_no_such_scope', true, 'children'); + select throws_like( + 'insert_bad_scope_id', + 'insert or update on table "iam_role" violates foreign key constraint "iam_scope_scope_id_fkey"', + 'scope_id must exist in iam_scope_org(scope_id)' + ); + + -- 1e) attempt referencing a project scope from iam_scope_project, expecting an error + prepare insert_wrong_scope_type as + insert into iam_role_org + (public_id, scope_id, grant_scope, grant_this_role_scope) + values + ('r_org_wrong_scope', 'p____bwidget', 'children', true); + select throws_like( + 'insert_wrong_scope_type', + 'insert or update on table "iam_role_org" violates foreign key constraint "iam_scope_org_fkey"', + 'must reference an org scope, not a project scope' + ); + + ------------------------------------------------------------------------------ + -- 2) testing grant_scope_update_time trigger + ------------------------------------------------------------------------------ + + -- 2a) insert a row -> expect it to set grant_scope_update_time (if triggered on insert) + prepare insert_with_grant_scope_update_time as + insert into iam_role_org + (public_id, scope_id, grant_scope, grant_scope_update_time) + values + ('r_org_2222222222', 'o_____widget', 'individual', null); + select lives_ok('insert_with_grant_scope_update_time'); + + select is( + (select grant_scope_update_time is not null + from iam_role_org + where public_id = 'r_org_2222222222'), + true, + 'grant_scope_update_time should be set right after insert if the trigger sets it' + ); + + -- 2b) update grant_this_role_scope => trigger should update grant_scope_update_time + prepare update_grant_this_role_scope as + update iam_role_org + set grant_this_role_scope = false + where public_id = 'r_org_2222222222'; + select lives_ok('update_grant_this_role_scope'); + + select is( + (select grant_scope_update_time is not null + from iam_role_org + where public_id = 'r_org_2222222222'), + true, + 'grant_scope_update_time should be updated after changing grant_this_role_scope' + ); + + ------------------------------------------------------------------------------ + -- 3) testing iam_role_global_individual_grant_scope table + ------------------------------------------------------------------------------ + + -- 3a) insert a valid row -> should succeed + prepare update_iam_role_org_to_individual_grant_scope as + update iam_role_org + set grant_scope = 'individual' + where public_id = 'r_op_sw__eng'; + select lives_ok('update_iam_role_org_to_individual_grant_scope'); + + prepare insert_valid_row as + insert into iam_role_org_individual_grant_scope (role_id, grant_scope, scope_id) + values ('r_op_sw__eng', 'individual', 'p____bwidget'); + select lives_ok('insert_valid_row'); + + -- 3b) verify individual grant scope was inserted + select is( + (select count(*) from iam_role_org_individual_grant_scope + where role_id = 'r_op_sw__eng' + and grant_scope = 'individual' + and scope_id = 'p____bwidget'), + 1::bigint, + 'individual grant scope was inserted' + ); + + -- 3c) verify create_time is set by trigger + select isnt( + (select create_time from iam_role_org_individual_grant_scope + where role_id = 'r_op_sw__eng' + and scope_id = 'p____bwidget'), + null, + 'create_time should be set on insert' + ); + + -- 3d) negative test: grant_scope != 'individual' + prepare insert_bad_grant_scope as + insert into iam_role_org_individual_grant_scope (role_id, grant_scope, scope_id) + values ('r_op_sw__eng', 'children', 'p____bwidget'); + select throws_like( + 'insert_bad_grant_scope', + 'new row for relation "iam_role_org_individual_grant_scope" violates check constraint "only_individual_grant_scope_allowed"', + 'grant_scope must be "individual"' + ); + + -- 3e) negative test: referencing a project scope that belongs to another org + prepare insert_wrong_role_project as + insert into iam_role_org_individual_grant_scope (role_id, grant_scope, scope_id) + values ('o_____widget', 'children', 'invalid_project'); + select throws_like( + 'insert_wrong_role_project', + 'project scope_id invalid_project not found in org', + 'ensure_project_belongs_to_role_org trigger enforces matching org' + ); + + select * from finish(); +rollback; diff --git a/internal/db/sqltest/tests/iam/iam_role_project.sql b/internal/db/sqltest/tests/iam/iam_role_project.sql new file mode 100644 index 0000000000..7263d945df --- /dev/null +++ b/internal/db/sqltest/tests/iam/iam_role_project.sql @@ -0,0 +1,94 @@ +-- copyright (c) hashicorp, inc. +-- spdx-license-identifier: busl-1.1 + +begin; +select plan(8); +select wtt_load('widgets', 'iam'); + +-------------------------------------------------------------------------------- +-- 1) test valid inserts +-------------------------------------------------------------------------------- +prepare insert_valid_project_role as + insert into iam_role_project + (public_id, scope_id) + values + ('r_proj_1111111111', 'p____bwidget'); + +select lives_ok('insert_valid_project_role'); + +-- verify the row actually got inserted in iam_role_project +select is( + (select count(*) from iam_role_project where public_id = 'r_proj_1111111111'), + 1::bigint, + 'one valid row inserted into iam_role_project' +); + +-- check that insert_role_subtype trigger created a corresponding row in iam_role +select is( + (select count(*) from iam_role where public_id = 'r_proj_1111111111'), + 1::bigint, + 'insert_role_subtype trigger inserted a row into iam_role' +); + +-- verify create_time is set (default_create_time_column trigger) +select isnt( + (select create_time from iam_role_project where public_id = 'r_proj_1111111111'), + null, + 'create_time is auto-set on insert' +); + +-------------------------------------------------------------------------------- +-- 2) test invalid inserts +-------------------------------------------------------------------------------- + +-- 2a) invalid project scope (not in iam_scope_project) +prepare insert_invalid_scope as + insert into iam_role_project + (public_id, scope_id) + values + ('r_proj_2222222222', 'o_1111111111'); +select throws_like( + 'insert_invalid_scope', + 'insert or update on table "iam_role" violates foreign key constraint "iam_scope_scope_id_fkey"', + 'must reference a valid project scope' +); + +-- 2b) duplicate primary ke +prepare insert_duplicate_role_id as + insert into iam_role_project + (public_id, scope_id) + values + ('r_proj_1111111111', 'p____bwidget'); +select throws_like( + 'insert_duplicate_role_id', + 'duplicate key value violates unique constraint "iam_role_pkey"', + 'primary key (public_id) is enforced' +); + +-------------------------------------------------------------------------------- +-- 3) test triggers for immutable_columns +-------------------------------------------------------------------------------- + +-- 3a) try updating immutable columns: scope_id, create_time +prepare update_scope_id as + update iam_role_project + set scope_id = 'p____bwidget2' + where public_id = 'r_proj_1111111111'; +select throws_like( + 'update_scope_id', + 'immutable column: iam_role_project.scope_id', + 'immutable_columns trigger prevents changing scope_id' +); + +prepare update_create_time as + update iam_role_project + set create_time = null + where public_id = 'r_proj_1111111111'; +select throws_like( + 'update_create_time', + 'immutable column: iam_role_project.create_time', + 'immutable_columns trigger prevents changing create_time' +); + +select * from finish(); +rollback; From 348dacd1a73bf766a8e1a1d0d9293ae4e6a0bbaa Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Wed, 12 Feb 2025 10:44:11 -0500 Subject: [PATCH 16/29] fix: update comments and enforce not null constraint on grant_scope fields in IAM role migrations --- .../oss/postgres/100/01_iam_role_global.up.sql | 6 ++++-- .../migrations/oss/postgres/100/02_iam_role_org.up.sql | 10 +++++----- 2 files changed, 9 insertions(+), 7 deletions(-) diff --git a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql index ef3c72ef8c..032c4247a2 100644 --- a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql @@ -16,7 +16,7 @@ begin; ) ); comment on table iam_role_global_grant_scope_enm is - 'iam_role_global_grant_scope_enm is an enumeration table for role grant scope types for for the iam_role_global table.'; + 'iam_role_global_grant_scope_enm is an enumeration table for role grant scope types for the iam_role_global table.'; -- Insert the predefined grant scope types for iam_role_global insert into iam_role_global_grant_scope_enm (name) @@ -75,6 +75,8 @@ begin; -- the last time the grant_this_role_scope and grant_scope columns were updated. -- This is used to represent the grant scope create_time column from the -- iam_role_grant_scope table in 83/01_iam_role_grant_scope.up.sql. + -- This matches the representation of the existing create_time field at the + -- role domain layer that indicates when the grant scope was created. create table iam_role_global ( public_id wt_role_id not null primary key constraint iam_role_fkey @@ -89,7 +91,7 @@ begin; name text, description text, grant_this_role_scope boolean not null default false, - grant_scope text + grant_scope text not null constraint iam_role_global_grant_scope_enm_fkey references iam_role_global_grant_scope_enm(name) on delete restrict diff --git a/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql b/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql index 54f5abc077..0e56a378e0 100644 --- a/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql @@ -37,7 +37,7 @@ begin; name text, description text, grant_this_role_scope boolean not null default false, - grant_scope text + grant_scope text not null constraint iam_role_org_grant_scope_enm_fkey references iam_role_org_grant_scope_enm(name) on delete restrict @@ -119,11 +119,11 @@ begin; as $$ begin perform - from iam_scope_project - join iam_role_org - on iam_role_org.scope_id = iam_scope_project.parent_id + from iam_scope_project + join iam_role_org + on iam_role_org.scope_id = iam_scope_project.parent_id where iam_scope_project.scope_id = new.scope_id - and iam_role_org.public_id = new.role_id; + and iam_role_org.public_id = new.role_id; if not found then raise exception 'project scope_id % not found in org', new.scope_id; end if; From c263a6fe426136d0b277a6c94e75e33c6da3b37a Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Wed, 12 Feb 2025 18:24:41 -0500 Subject: [PATCH 17/29] update sql test grants to use valid grant strings --- .../db/sqltest/initdb.d/01_colors_persona.sql | 22 +++++++++---------- .../sqltest/initdb.d/03_widgets_persona.sql | 18 +++++++-------- 2 files changed, 20 insertions(+), 20 deletions(-) diff --git a/internal/db/sqltest/initdb.d/01_colors_persona.sql b/internal/db/sqltest/initdb.d/01_colors_persona.sql index 9ce83de931..98ba9ac126 100644 --- a/internal/db/sqltest/initdb.d/01_colors_persona.sql +++ b/internal/db/sqltest/initdb.d/01_colors_persona.sql @@ -137,17 +137,17 @@ begin; insert into iam_role_grant (role_id, canonical_grant, raw_grant) values - ('r_gg_____buy', 'type=*;action=purchase', 'purchase anything'), - ('r_gg____shop', 'type=*;action=view', 'view anything'), - ('r_go____name', 'type=group;action=name', 'name colors'), - ('r_gp____spec', 'type=group;action=inspect', 'inspect colors'), - ('r_oo_____art', 'type=group;action=create', 'create color'), - ('r_op_bc__art', 'type=group;action=create', 'create color'), - ('r_op_rc__art', 'type=group;action=create', 'create color'), - ('r_op_gc__art', 'type=group;action=create', 'create color'), - ('r_pp_bc__mix', 'type=group;action=mix', 'mix color'), - ('r_pp_rc__mix', 'type=group;action=mix', 'mix color'), - ('r_pp_gc__mix', 'type=group;action=mix', 'mix color'); + ('r_gg_____buy', 'type=*;actions=update', 'type=*;actions=update'), + ('r_gg____shop', 'type=*;actions=read', 'type=*;actions=read'), + ('r_go____name', 'type=group;action=create,update,read,list', 'type=group;action=create,update,read,list'), + ('r_gp____spec', 'type=group;action=delete', 'type=group;action=delete'), + ('r_oo_____art', 'type=group;action=create', 'type=group;action=create'), + ('r_op_bc__art', 'type=group;action=create', 'type=group;action=create'), + ('r_op_rc__art', 'type=group;action=create', 'type=group;action=create'), + ('r_op_gc__art', 'type=group;action=create', 'type=group;action=create'), + ('r_pp_bc__mix', 'type=group;action=add-members', 'type=group;action=add-members'), + ('r_pp_rc__mix', 'type=group;action=set-members', 'type=group;action=set-members'), + ('r_pp_gc__mix', 'type=group;action=delete-members', 'type=group;action=delete-members'); insert into iam_group_role (role_id, principal_id) diff --git a/internal/db/sqltest/initdb.d/03_widgets_persona.sql b/internal/db/sqltest/initdb.d/03_widgets_persona.sql index 5193028bf7..463884a5fc 100644 --- a/internal/db/sqltest/initdb.d/03_widgets_persona.sql +++ b/internal/db/sqltest/initdb.d/03_widgets_persona.sql @@ -55,10 +55,10 @@ begin; ('g___ws-group', 'u_____waylon'); insert into iam_role_org - (scope_id, public_id, name) + (scope_id, public_id, name, grant_scope) values - ('o_____widget', 'r_op_sw__eng', 'Small Widget Engineer'), - ('o_____widget', 'r_oo_____eng', 'Widget Engineer'); + ('o_____widget', 'r_op_sw__eng', 'Small Widget Engineer', 'individual'), + ('o_____widget', 'r_oo_____eng', 'Widget Engineer', 'individual'); insert into iam_role_project (scope_id, public_id, name) @@ -79,12 +79,12 @@ begin; values -- ('r_gg_____buy', 'type=*;action=purchase', 'purchase anything'), -- ('r_gg____shop', 'type=*;action=view', 'view anything'), - ('r_oo_____eng', 'type=target;action=design', 'design widget'), - ('r_op_sw__eng', 'type=target;action=design', 'design widget'), - ('r_op_sw__eng', 'type=target;action=tune', 'tune widget'), - ('r_op_sw__eng', 'type=target;action=clean', 'clean widget'), - ('r_pp_bw__bld', 'type=target;action=build', 'build widget'), - ('r_pp_sw__bld', 'type=target;action=build', 'build widget'); + ('r_oo_____eng', 'type=target;action=create,update,authorize-session', 'type=target;action=create,update,authorize-session'), + ('r_op_sw__eng', 'type=target;action=add-credential-sources,remove-credential-sources,set-credential-sources', 'type=target;action=add-credential-sources,remove-credential-sources,set-credential-sources'), + ('r_op_sw__eng', 'type=target;action=add-host-sources,remove-host-sources,set-host-sources', 'type=target;action=add-host-sources,remove-host-sources,set-host-sources'), + ('r_op_sw__eng', 'type=target;action=read,list', 'type=target;action=read,list'), + ('r_pp_bw__bld', 'type=target;action=create,delete', 'type=target;action=create,delete'), + ('r_pp_sw__bld', 'type=target;action=authorize-session', 'type=target;action=authorize-session'); insert into iam_group_role (role_id, principal_id) From 3f95ab5311fa12bfece53317c832fafdf1f1736e Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Wed, 12 Feb 2025 18:25:09 -0500 Subject: [PATCH 18/29] add more test coverage for iam_grant with multiple grant string combinations --- .../db/sqltest/initdb.d/01_colors_persona.sql | 4 +- internal/db/sqltest/tests/iam/iam_grant.sql | 96 +++++++++++++++---- .../db/sqltest/tests/iam/iam_role_project.sql | 4 +- 3 files changed, 82 insertions(+), 22 deletions(-) diff --git a/internal/db/sqltest/initdb.d/01_colors_persona.sql b/internal/db/sqltest/initdb.d/01_colors_persona.sql index 98ba9ac126..f6cd09154d 100644 --- a/internal/db/sqltest/initdb.d/01_colors_persona.sql +++ b/internal/db/sqltest/initdb.d/01_colors_persona.sql @@ -135,11 +135,11 @@ begin; ('r_gg____shop', 'global'); insert into iam_role_grant - (role_id, canonical_grant, raw_grant) + (role_id, canonical_grant, raw_grant) values ('r_gg_____buy', 'type=*;actions=update', 'type=*;actions=update'), ('r_gg____shop', 'type=*;actions=read', 'type=*;actions=read'), - ('r_go____name', 'type=group;action=create,update,read,list', 'type=group;action=create,update,read,list'), + ('r_go____name', 'type=group;action=create,update,read,list', 'type=group;action=create,update,read,'), ('r_gp____spec', 'type=group;action=delete', 'type=group;action=delete'), ('r_oo_____art', 'type=group;action=create', 'type=group;action=create'), ('r_op_bc__art', 'type=group;action=create', 'type=group;action=create'), diff --git a/internal/db/sqltest/tests/iam/iam_grant.sql b/internal/db/sqltest/tests/iam/iam_grant.sql index 34d8957d4e..1f5c9c33fa 100644 --- a/internal/db/sqltest/tests/iam/iam_grant.sql +++ b/internal/db/sqltest/tests/iam/iam_grant.sql @@ -1,18 +1,18 @@ --- copyright (c) hashicorp, inc. --- spdx-license-identifier: busl-1.1 +-- Copyright (c) HashiCorp, Inc. +-- SPDX-License-Identifier: BUSL-1.1 begin; -select plan(9); +select plan(15); select wtt_load('widgets', 'iam'); +-- insert canonical_grant with valid resource +-- validate the resource is set to 'scope' prepare insert_grant_scope as insert into iam_grant (canonical_grant) values ('type=scope;others=stuff;'); - select lives_ok('insert_grant_scope'); - select is( (select resource from iam_grant @@ -21,35 +21,33 @@ select is( 'resource should be set to "scope" by set_resource() trigger' ); +-- insert canonical_grant with no type +-- validate the resource is set to 'unknown' prepare insert_grant_no_type as insert into iam_grant (canonical_grant) values ('no_type_at_all;'); - select lives_ok('insert_grant_no_type'); - select is( (select resource from iam_grant where canonical_grant = 'no_type_at_all;'), 'unknown', - 'resource should default to "unknown" if type=... is not found' + 'resource should default to "unknown" if type is not found' ); +-- insert canonical_grant with type=role,group +-- validate the resource is set to 'role' prepare insert_grant_role as insert into iam_grant (canonical_grant) values - ('type=role;foo=bar;'); -select lives_ok('insert_grant_role'); - -select is( - (select resource - from iam_grant - where canonical_grant = 'type=role;foo=bar;'), - 'role', - 'resource should be set to "role"' + ('type=role,group;foo=bar;'); +select throws_like( + 'insert_grant_role', + 'insert or update on table "iam_grant" violates foreign key constraint "resource_enm_fkey"', + 'inserting a resource not in resource_enm should fail because type is not a single value' ); -- the set_resource() trigger will set resource='bogus', but we did not insert 'bogus' @@ -65,13 +63,14 @@ select throws_like( 'inserting a resource not in resource_enm should fail' ); +-- insert a duplicate canonical_grant +-- validate that the primary key constraint is enforced prepare insert_dup_grant_1 as insert into iam_grant (canonical_grant) values ('duplicate_grant;type=scope;'); select lives_ok('insert_dup_grant_1'); - prepare insert_dup_grant_2 as insert into iam_grant (canonical_grant) @@ -83,5 +82,66 @@ select throws_like( 'primary key (canonical_grant) is enforced' ); +-- insert a canonical grant string with wildcards for id, type, actions, and output_fields +-- validate that the resource is set to '*' +prepare insert_grant_wildcard_actions as + insert into iam_grant + (canonical_grant) + values + ('id=*;type=*;actions=*;output_fields=*'); +select lives_ok('insert_grant_wildcard_actions'); +select is( + (select resource + from iam_grant + where canonical_grant = 'id=*;type=*;actions=*;output_fields=*'), + '*', + 'resource should be set to "*" if type is "*"' +); + +-- insert a canonical grant string with single action, single id, single output_field and type=host +-- validate that the resource is set to 'host' +prepare insert_grant_single_action as + insert into iam_grant + (canonical_grant) + values + ('id=o_1234;type=host;actions=create;output_fields=id'); +select lives_ok('insert_grant_single_action'); +select is( + (select resource + from iam_grant + where canonical_grant = 'id=o_1234;type=host;actions=create;output_fields=id'), + 'host', + 'resource should be set to "host" if type is "host"' +); + +-- insert a canonical grant string with type=group, multiple actions, single type and multiple output_fields +-- validate that the resource is set to 'role' +prepare insert_grant_role_multiple_actions as + insert into iam_grant + (canonical_grant) + values + ('id=o_1234,o_4567;type=group;actions=create,update;output_fields=id,name'); +select lives_ok('insert_grant_role_multiple_actions'); +select is( + (select resource + from iam_grant + where canonical_grant = 'id=o_1234,o_4567;type=group;actions=create,update;output_fields=id,name'), + 'group', + 'resource should be set to "group" if type is "group"' +); + +-- insert a canonical grant string with with multiple types +-- validate that the resource is set to 'role' +prepare insert_grant_multiple_types as + insert into iam_grant + (canonical_grant) + values + ('id=o_1234,o_4567;type=target,role,group;actions=create,update;output_fields=id,name'); +select throws_like( + 'insert_grant_multiple_types', + 'insert or update on table "iam_grant" violates foreign key constraint "resource_enm_fkey"', + 'inserting a resource not in resource_enm should fail because type is not a single value' +); + select * from finish(); rollback; diff --git a/internal/db/sqltest/tests/iam/iam_role_project.sql b/internal/db/sqltest/tests/iam/iam_role_project.sql index 7263d945df..70a17213db 100644 --- a/internal/db/sqltest/tests/iam/iam_role_project.sql +++ b/internal/db/sqltest/tests/iam/iam_role_project.sql @@ -1,5 +1,5 @@ --- copyright (c) hashicorp, inc. --- spdx-license-identifier: busl-1.1 +-- Copyright (c) HashiCorp, Inc. +-- SPDX-License-Identifier: BUSL-1.1 begin; select plan(8); From c8193f835a94374a24ce7c6f0ddd4e5cba4b9e35 Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Wed, 19 Feb 2025 13:15:46 -0500 Subject: [PATCH 19/29] remove not null for primary keys --- .../migrations/oss/postgres/100/01_iam_role_global.up.sql | 2 +- .../schema/migrations/oss/postgres/100/02_iam_role_org.up.sql | 2 +- 2 files changed, 2 insertions(+), 2 deletions(-) diff --git a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql index 032c4247a2..6373bf16a4 100644 --- a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql @@ -78,7 +78,7 @@ begin; -- This matches the representation of the existing create_time field at the -- role domain layer that indicates when the grant scope was created. create table iam_role_global ( - public_id wt_role_id not null primary key + public_id wt_role_id primary key constraint iam_role_fkey references iam_role(public_id) on delete cascade diff --git a/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql b/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql index 0e56a378e0..a0c19fa77f 100644 --- a/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql @@ -5,7 +5,7 @@ begin; -- Create the enumeration table for the grant scope types for the org iam_role create table iam_role_org_grant_scope_enm ( - name text not null primary key + name text primary key constraint only_predefined_scope_types_allowed check( name in ( From d0f44892663f179e3e46ac9989d522cbb75c5dc1 Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Wed, 26 Feb 2025 10:16:37 -0500 Subject: [PATCH 20/29] fixup! address PR comments - name all unique constraints and make grant_scope the first column - set grant_scope column as not null - add cascade delete on foreign key constraints - rename `resource_enm` to `iam_grant_resource_enm` --- .../postgres/100/01_iam_role_global.up.sql | 9 ++++--- .../oss/postgres/100/02_iam_role_org.up.sql | 9 ++++--- .../oss/postgres/100/04_resource.up.sql | 8 +++--- .../oss/postgres/100/05_iam_grant.up.sql | 4 +-- internal/db/sqltest/tests/iam/iam_grant.sql | 26 +++++++++---------- 5 files changed, 31 insertions(+), 25 deletions(-) diff --git a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql index 6373bf16a4..048383e47d 100644 --- a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql @@ -101,7 +101,8 @@ begin; grant_scope_update_time wt_timestamp, create_time wt_timestamp, update_time wt_timestamp, - unique(public_id, grant_scope) + constraint iam_role_global_grant_scope_public_id_uq + unique(grant_scope, public_id) ); comment on table iam_role_global is 'iam_role_global is the subtype table for the global role. grant_this_role_scope_update_time and grant_scope_update_time are used to track the last time the grant_this_role_scope and grant_scope columns were updated.'; @@ -144,7 +145,7 @@ begin; -- and since it is also a foreign key to the iam_role_global -- grant_scope, it ensures that iam_role_global is set to 'individual' -- if this table is populated for the corresponding role. - grant_scope text + grant_scope text not null constraint only_individual_grant_scope_allowed check( grant_scope = 'individual' @@ -160,7 +161,9 @@ begin; ), constraint iam_role_global_grant_scope_fkey foreign key (role_id, grant_scope) - references iam_role_global(public_id, grant_scope), + references iam_role_global(public_id, grant_scope) + on delete cascade + on update cascade, create_time wt_timestamp ); comment on table iam_role_global_individual_grant_scope is diff --git a/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql b/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql index a0c19fa77f..053c89cb2e 100644 --- a/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql @@ -47,7 +47,8 @@ begin; grant_scope_update_time wt_timestamp, create_time wt_timestamp, update_time wt_timestamp, - unique(public_id, grant_scope) + constraint iam_role_org_grant_scope_public_id_uq + unique(grant_scope, public_id) ); comment on table iam_role_org is 'iam_role_org is a subtype table of the iam_role table. It is used to store roles that are scoped to an org.'; @@ -90,7 +91,7 @@ begin; -- and since it is also a foreign key to the iam_role_org -- grant_scope, it ensures that iam_role_org is set to 'individual' -- if this table is populated for the corresponding role. - grant_scope text + grant_scope text not null constraint only_individual_grant_scope_allowed check( grant_scope = 'individual' @@ -102,7 +103,9 @@ begin; on update cascade, constraint iam_role_org_grant_scope_fkey foreign key (role_id, grant_scope) - references iam_role_org(public_id, grant_scope), + references iam_role_org(public_id, grant_scope) + on delete cascade + on update cascade, create_time wt_timestamp ); comment on table iam_role_org_individual_grant_scope is diff --git a/internal/db/schema/migrations/oss/postgres/100/04_resource.up.sql b/internal/db/schema/migrations/oss/postgres/100/04_resource.up.sql index 46e0cb9ede..7d8d3e7304 100644 --- a/internal/db/schema/migrations/oss/postgres/100/04_resource.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/04_resource.up.sql @@ -3,7 +3,7 @@ begin; - create table resource_enm ( + create table iam_grant_resource_enm ( name text primary key constraint only_predefined_resource_types_allowed check( @@ -36,11 +36,11 @@ begin; ) ) ); - comment on table resource_enm is - 'resource_enm is an enumeration table for resource types.'; + comment on table iam_grant_resource_enm is + 'iam_grant_resource_enm is an enumeration table for resource types.'; -- Insert the predefined resource types - insert into resource_enm (name) + insert into iam_grant_resource_enm (name) values ('*'), ('alias'), diff --git a/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql b/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql index 6b5c7883ec..8dc7f97fa3 100644 --- a/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql @@ -9,8 +9,8 @@ begin; create table iam_grant ( canonical_grant text primary key, resource text not null - constraint resource_enm_fkey - references resource_enm(name) + constraint iam_grant_resource_enm_fkey + references iam_grant_resource_enm(name) on delete restrict on update cascade ); diff --git a/internal/db/sqltest/tests/iam/iam_grant.sql b/internal/db/sqltest/tests/iam/iam_grant.sql index 1f5c9c33fa..03250101fa 100644 --- a/internal/db/sqltest/tests/iam/iam_grant.sql +++ b/internal/db/sqltest/tests/iam/iam_grant.sql @@ -46,8 +46,8 @@ prepare insert_grant_role as ('type=role,group;foo=bar;'); select throws_like( 'insert_grant_role', - 'insert or update on table "iam_grant" violates foreign key constraint "resource_enm_fkey"', - 'inserting a resource not in resource_enm should fail because type is not a single value' + 'insert or update on table "iam_grant" violates foreign key constraint "iam_grant_resource_enm_fkey"', + 'inserting a resource not in iam_grant_resource_enm should fail because type is not a single value' ); -- the set_resource() trigger will set resource='bogus', but we did not insert 'bogus' @@ -59,8 +59,8 @@ prepare insert_grant_bogus as ('type=bogus;some=thing;'); select throws_like( 'insert_grant_bogus', - 'insert or update on table "iam_grant" violates foreign key constraint "resource_enm_fkey"', - 'inserting a resource not in resource_enm should fail' + 'insert or update on table "iam_grant" violates foreign key constraint "iam_grant_resource_enm_fkey"', + 'inserting a resource not in iam_grant_resource_enm should fail' ); -- insert a duplicate canonical_grant @@ -88,12 +88,12 @@ prepare insert_grant_wildcard_actions as insert into iam_grant (canonical_grant) values - ('id=*;type=*;actions=*;output_fields=*'); + ('ids=*;type=*;actions=*;output_fields=*'); select lives_ok('insert_grant_wildcard_actions'); select is( (select resource from iam_grant - where canonical_grant = 'id=*;type=*;actions=*;output_fields=*'), + where canonical_grant = 'ids=*;type=*;actions=*;output_fields=*'), '*', 'resource should be set to "*" if type is "*"' ); @@ -104,12 +104,12 @@ prepare insert_grant_single_action as insert into iam_grant (canonical_grant) values - ('id=o_1234;type=host;actions=create;output_fields=id'); + ('ids=o_1234;type=host;actions=create;output_fields=id'); select lives_ok('insert_grant_single_action'); select is( (select resource from iam_grant - where canonical_grant = 'id=o_1234;type=host;actions=create;output_fields=id'), + where canonical_grant = 'ids=o_1234;type=host;actions=create;output_fields=id'), 'host', 'resource should be set to "host" if type is "host"' ); @@ -120,12 +120,12 @@ prepare insert_grant_role_multiple_actions as insert into iam_grant (canonical_grant) values - ('id=o_1234,o_4567;type=group;actions=create,update;output_fields=id,name'); + ('ids=o_1234,o_4567;type=group;actions=create,update;output_fields=id,name'); select lives_ok('insert_grant_role_multiple_actions'); select is( (select resource from iam_grant - where canonical_grant = 'id=o_1234,o_4567;type=group;actions=create,update;output_fields=id,name'), + where canonical_grant = 'ids=o_1234,o_4567;type=group;actions=create,update;output_fields=id,name'), 'group', 'resource should be set to "group" if type is "group"' ); @@ -136,11 +136,11 @@ prepare insert_grant_multiple_types as insert into iam_grant (canonical_grant) values - ('id=o_1234,o_4567;type=target,role,group;actions=create,update;output_fields=id,name'); + ('ids=o_1234,o_4567;type=target,role,group;actions=create,update;output_fields=id,name'); select throws_like( 'insert_grant_multiple_types', - 'insert or update on table "iam_grant" violates foreign key constraint "resource_enm_fkey"', - 'inserting a resource not in resource_enm should fail because type is not a single value' + 'insert or update on table "iam_grant" violates foreign key constraint "iam_grant_resource_enm_fkey"', + 'inserting a resource not in iam_grant_resource_enm should fail because type is not a single value' ); select * from finish(); From 8a890ba48f2a6bc892bd33cc0dd7f1f9c8244fed Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Wed, 26 Feb 2025 11:48:10 -0500 Subject: [PATCH 21/29] add more iam_grants test coverage --- internal/db/sqltest/tests/iam/iam_grant.sql | 142 +++++++++++++++++++- 1 file changed, 137 insertions(+), 5 deletions(-) diff --git a/internal/db/sqltest/tests/iam/iam_grant.sql b/internal/db/sqltest/tests/iam/iam_grant.sql index 03250101fa..dfa1f1694c 100644 --- a/internal/db/sqltest/tests/iam/iam_grant.sql +++ b/internal/db/sqltest/tests/iam/iam_grant.sql @@ -2,7 +2,7 @@ -- SPDX-License-Identifier: BUSL-1.1 begin; -select plan(15); +select plan(31); select wtt_load('widgets', 'iam'); -- insert canonical_grant with valid resource @@ -84,12 +84,12 @@ select throws_like( -- insert a canonical grant string with wildcards for id, type, actions, and output_fields -- validate that the resource is set to '*' -prepare insert_grant_wildcard_actions as +prepare insert_grant_wildcard as insert into iam_grant (canonical_grant) values ('ids=*;type=*;actions=*;output_fields=*'); -select lives_ok('insert_grant_wildcard_actions'); +select lives_ok('insert_grant_wildcard'); select is( (select resource from iam_grant @@ -115,7 +115,7 @@ select is( ); -- insert a canonical grant string with type=group, multiple actions, single type and multiple output_fields --- validate that the resource is set to 'role' +-- validate that the resource is set to 'group' prepare insert_grant_role_multiple_actions as insert into iam_grant (canonical_grant) @@ -131,7 +131,7 @@ select is( ); -- insert a canonical grant string with with multiple types --- validate that the resource is set to 'role' +-- the insert should fail because the resource is not a single value prepare insert_grant_multiple_types as insert into iam_grant (canonical_grant) @@ -143,5 +143,137 @@ select throws_like( 'inserting a resource not in iam_grant_resource_enm should fail because type is not a single value' ); +-- insert a canonical grant string with type with dash +-- validate that the resource is set to 'credential-library' +prepare insert_grant_with_dash as + insert into iam_grant + (canonical_grant) + values + ('ids=*;type=credential-library;actions=create;output_fields=id'); +select lives_ok('insert_grant_with_dash'); +select is( + (select resource + from iam_grant + where canonical_grant = 'ids=*;type=credential-library;actions=create;output_fields=id'), + 'credential-library', + 'resource should be set to "credential-library" if type is "credential-library"' +); + +-- insert a canonical grant string with type with underscore +-- the insert should fail because a resource with underscore is not in the resource_enm table +prepare insert_grant_with_underscore as + insert into iam_grant + (canonical_grant) + values + ('ids=*;type=credential_library;actions=create;output_fields=id'); +select throws_like( + 'insert_grant_with_underscore', + 'insert or update on table "iam_grant" violates foreign key constraint "iam_grant_resource_enm_fkey"', + 'inserting a a resource with underscore should fail' +); + +-- insert a canonical grant string with type malformed with no semicolon +-- the insert should fail because the type is malformed +prepare insert_grant_malformed_type_with_no_semicolon as + insert into iam_grant + (canonical_grant) + values + ('ids=*;type=credential-library actions=create;output_fields=id'); +select throws_like( + 'insert_grant_malformed_type_with_no_semicolon', + 'insert or update on table "iam_grant" violates foreign key constraint "iam_grant_resource_enm_fkey"', + 'inserting a resource with a malformed type should fail' +); + +-- insert a canonical grant string with type malformed with no equals sign +prepare insert_grant_malformed_type_with_no_equals as + insert into iam_grant + (canonical_grant) + values + ('ids=*;type;actions=create;output_fields=id'); +select lives_ok('insert_grant_malformed_type_with_no_equals'); +select is( + (select resource + from iam_grant + where canonical_grant = 'ids=*;type;actions=create;output_fields=id'), + 'unknown', + 'resource should default to "unknown" if the type has no equals sign' +); + +-- insert a canonical grant string with type malformed with no value +prepare insert_grant_malformed_type_with_no_value as + insert into iam_grant + (canonical_grant) + values + ('ids=*;type=;actions=create;output_fields=id'); +select lives_ok('insert_grant_malformed_type_with_no_value'); +select is( + (select resource + from iam_grant + where canonical_grant = 'ids=*;type=;actions=create;output_fields=id'), + 'unknown', + 'resource should default to "unknown" if the type has no value' +); + +-- insert a canonical grant string with type malformed with no type +prepare insert_grant_malformed_type_with_no_type as + insert into iam_grant + (canonical_grant) + values + ('ids=*;actions=create;output_fields=id'); +select lives_ok('insert_grant_malformed_type_with_no_type'); +select is( + (select resource + from iam_grant + where canonical_grant = 'ids=*;actions=create;output_fields=id'), + 'unknown', + 'resource should default to "unknown" if the type is not found' +); + +-- insert a canonical grant string with type malformed with double ids semicolon +prepare insert_grant_malformed_type_with_double_ids_semicolon as + insert into iam_grant + (canonical_grant) + values + ('ids=*;;type=credential-library;actions=create;output_fields=id'); +select lives_ok('insert_grant_malformed_type_with_double_ids_semicolon'); +select is( + (select resource + from iam_grant + where canonical_grant = 'ids=*;;type=credential-library;actions=create;output_fields=id'), + 'credential-library', + 'resource should be set to "credential-library"' +); + +-- insert a canonical grant string with type at the end of the string +prepare insert_grant_malformed_type_with_type_at_the_end as + insert into iam_grant + (canonical_grant) + values + ('ids=*;actions=create;output_fields=id;type=credential-library'); +select lives_ok('insert_grant_malformed_type_with_type_at_the_end'); +select is( + (select resource + from iam_grant + where canonical_grant = 'ids=*;actions=create;output_fields=id;type=credential-library'), + 'unknown', + 'resource should default to "unknown" if the type is not in the expected order' +); + +-- insert a canonical grant string with type malformed with semicolon after type +prepare insert_grant_malformed_type_with_semicolon_after_type as + insert into iam_grant + (canonical_grant) + values + ('ids=*;type;=credential-library;actions=create;output_fields=id;'); +select lives_ok('insert_grant_malformed_type_with_semicolon_after_type'); +select is( + (select resource + from iam_grant + where canonical_grant = 'ids=*;type;=credential-library;actions=create;output_fields=id;'), + 'unknown', + 'resource should default to "unknown" if the type is not found' +); + select * from finish(); rollback; From 3e65df0e78659422fff1a5635c83aeb6782f0efa Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Mon, 3 Mar 2025 00:23:13 -0500 Subject: [PATCH 22/29] update set_resource function to fail when a canonical_grant is malformed --- .../oss/postgres/100/05_iam_grant.up.sql | 28 ++++-- internal/db/sqltest/tests/iam/iam_grant.sql | 90 +++++++++---------- 2 files changed, 64 insertions(+), 54 deletions(-) diff --git a/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql b/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql index 8dc7f97fa3..6b5fa9d025 100644 --- a/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql @@ -20,22 +20,34 @@ begin; create index iam_grant_resource_ix on iam_grant (resource); - create function set_resource() returns trigger + create or replace function set_resource() returns trigger as $$ - declare resource text[]; + declare type_matches text[]; begin - select regexp_matches(new.canonical_grant, 'type=([^;]+);') - into resource; - if resource is null then - new.resource = 'unknown'; + -- validate that every token is in the form key=value + if not new.canonical_grant ~ '^(?:[^;=]+=[^;=]+)(?:;[^;=]+=[^;=]+)*;?$' then + raise exception 'malformed grant: %', new.canonical_grant; + end if; + + -- Extract all "type" tokens from the canonical_grant string + select array_agg(t[1]) + into type_matches + from regexp_matches(new.canonical_grant, '(?<=^|;)type=([^;]+)(?=;|$)', 'g') AS t; + + -- if there are multiple canonical grant types specified, throw an error. + -- Ensure that the canonical_grant type is only referencing a single resource + if type_matches is not null and array_length(type_matches, 1) > 1 then + raise exception 'multiple type tokens in grant. only one type expected: %', new.canonical_grant; + elsif type_matches is not null and array_length(type_matches, 1) = 1 then + new.resource := type_matches[1]; else - new.resource = resource[1]; + new.resource := 'unknown'; end if; return new; end $$ language plpgsql; comment on function set_resource() is - 'set_resource is a trigger function that sets the resource column based on the canonical_grant.'; + 'set_resource is a trigger function that validates the canonical grant string and sets the resource column based on the "type" token. Malformed tokens raise an exception. A valid grant without a type token results in resource being set to "unknown".'; create trigger set_resource before insert on iam_grant for each row execute procedure set_resource(); diff --git a/internal/db/sqltest/tests/iam/iam_grant.sql b/internal/db/sqltest/tests/iam/iam_grant.sql index dfa1f1694c..3d7db95b29 100644 --- a/internal/db/sqltest/tests/iam/iam_grant.sql +++ b/internal/db/sqltest/tests/iam/iam_grant.sql @@ -2,7 +2,7 @@ -- SPDX-License-Identifier: BUSL-1.1 begin; -select plan(31); +select plan(27); select wtt_load('widgets', 'iam'); -- insert canonical_grant with valid resource @@ -22,19 +22,16 @@ select is( ); -- insert canonical_grant with no type --- validate the resource is set to 'unknown' -prepare insert_grant_no_type as +-- the insert should fail because the type is malformed +prepare insert_malformed_grant as insert into iam_grant (canonical_grant) values ('no_type_at_all;'); -select lives_ok('insert_grant_no_type'); -select is( - (select resource - from iam_grant - where canonical_grant = 'no_type_at_all;'), - 'unknown', - 'resource should default to "unknown" if type is not found' +select throws_like( + 'insert_malformed_grant', + 'malformed grant: no_type_at_all;', + 'inserting a grant that is malformed should fail' ); -- insert canonical_grant with type=role,group @@ -69,13 +66,13 @@ prepare insert_dup_grant_1 as insert into iam_grant (canonical_grant) values - ('duplicate_grant;type=scope;'); + ('ids=*;type=credential-library;actions=create'); select lives_ok('insert_dup_grant_1'); prepare insert_dup_grant_2 as insert into iam_grant (canonical_grant) values - ('duplicate_grant;type=scope;'); + ('ids=*;type=credential-library;actions=create'); select throws_like( 'insert_dup_grant_2', 'duplicate key value violates unique constraint "iam_grant_pkey"', @@ -181,7 +178,7 @@ prepare insert_grant_malformed_type_with_no_semicolon as ('ids=*;type=credential-library actions=create;output_fields=id'); select throws_like( 'insert_grant_malformed_type_with_no_semicolon', - 'insert or update on table "iam_grant" violates foreign key constraint "iam_grant_resource_enm_fkey"', + 'malformed grant: ids=*;type=credential-library actions=create;output_fields=id', 'inserting a resource with a malformed type should fail' ); @@ -191,13 +188,10 @@ prepare insert_grant_malformed_type_with_no_equals as (canonical_grant) values ('ids=*;type;actions=create;output_fields=id'); -select lives_ok('insert_grant_malformed_type_with_no_equals'); -select is( - (select resource - from iam_grant - where canonical_grant = 'ids=*;type;actions=create;output_fields=id'), - 'unknown', - 'resource should default to "unknown" if the type has no equals sign' +select throws_like( + 'insert_grant_malformed_type_with_no_equals', + 'malformed grant: ids=*;type;actions=create;output_fields=id', + 'inserting a resource with a malformed type should fail' ); -- insert a canonical grant string with type malformed with no value @@ -206,16 +200,13 @@ prepare insert_grant_malformed_type_with_no_value as (canonical_grant) values ('ids=*;type=;actions=create;output_fields=id'); -select lives_ok('insert_grant_malformed_type_with_no_value'); -select is( - (select resource - from iam_grant - where canonical_grant = 'ids=*;type=;actions=create;output_fields=id'), - 'unknown', - 'resource should default to "unknown" if the type has no value' +select throws_like( + 'insert_grant_malformed_type_with_no_value', + 'malformed grant: ids=*;type=;actions=create;output_fields=id', + 'inserting a resource with a malformed type should fail' ); --- insert a canonical grant string with type malformed with no type +-- insert a canonical grant string with with no type prepare insert_grant_malformed_type_with_no_type as insert into iam_grant (canonical_grant) @@ -236,28 +227,25 @@ prepare insert_grant_malformed_type_with_double_ids_semicolon as (canonical_grant) values ('ids=*;;type=credential-library;actions=create;output_fields=id'); -select lives_ok('insert_grant_malformed_type_with_double_ids_semicolon'); -select is( - (select resource - from iam_grant - where canonical_grant = 'ids=*;;type=credential-library;actions=create;output_fields=id'), - 'credential-library', - 'resource should be set to "credential-library"' +select throws_like( + 'insert_grant_malformed_type_with_double_ids_semicolon', + 'malformed grant: ids=*;;type=credential-library;actions=create;output_fields=id', + 'inserting a resource with a malformed type should fail' ); -- insert a canonical grant string with type at the end of the string -prepare insert_grant_malformed_type_with_type_at_the_end as +prepare insert_grant_with_type_at_the_end as insert into iam_grant (canonical_grant) values ('ids=*;actions=create;output_fields=id;type=credential-library'); -select lives_ok('insert_grant_malformed_type_with_type_at_the_end'); +select lives_ok('insert_grant_with_type_at_the_end'); select is( (select resource from iam_grant where canonical_grant = 'ids=*;actions=create;output_fields=id;type=credential-library'), - 'unknown', - 'resource should default to "unknown" if the type is not in the expected order' + 'credential-library', + 'resource should be set to "credential-library" if type is "credential-library"' ); -- insert a canonical grant string with type malformed with semicolon after type @@ -266,13 +254,23 @@ prepare insert_grant_malformed_type_with_semicolon_after_type as (canonical_grant) values ('ids=*;type;=credential-library;actions=create;output_fields=id;'); -select lives_ok('insert_grant_malformed_type_with_semicolon_after_type'); -select is( - (select resource - from iam_grant - where canonical_grant = 'ids=*;type;=credential-library;actions=create;output_fields=id;'), - 'unknown', - 'resource should default to "unknown" if the type is not found' +select throws_like( + 'insert_grant_malformed_type_with_semicolon_after_type', + 'malformed grant: ids=*;type;=credential-library;actions=create;output_fields=id;', + 'inserting a resource with a malformed type should fail' +); + +-- insert a canonical grant string with multiple type tokens +-- the insert should fail because there are multiple type tokens +prepare insert_grant_multiple_type_specified as + insert into iam_grant + (canonical_grant) + values + ('ids=o_1234,o_4567;type=target;type=session;actions=create,update;output_fields=id,name'); +select throws_like( + 'insert_grant_multiple_type_specified', + 'multiple type tokens in grant. only one type expected: ids=o_1234,o_4567;type=target;type=session;actions=create,update;output_fields=id,name', + 'inserting a resource with multiple type tokens should fail' ); select * from finish(); From c3ac100e29c63a16874ae522dca847454d367bd8 Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Mon, 3 Mar 2025 00:33:40 -0500 Subject: [PATCH 23/29] update case of sql to match other sql files --- .../db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql b/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql index 6b5fa9d025..5eca88e70d 100644 --- a/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql @@ -32,7 +32,7 @@ begin; -- Extract all "type" tokens from the canonical_grant string select array_agg(t[1]) into type_matches - from regexp_matches(new.canonical_grant, '(?<=^|;)type=([^;]+)(?=;|$)', 'g') AS t; + from regexp_matches(new.canonical_grant, '(?<=^|;)type=([^;]+)(?=;|$)', 'g') as t; -- if there are multiple canonical grant types specified, throw an error. -- Ensure that the canonical_grant type is only referencing a single resource From 907f2631e618f7d816a127653fac4fb6ca2a4655 Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Mon, 3 Mar 2025 14:40:59 -0500 Subject: [PATCH 24/29] create new wt_canonical_grant domain --- .../oss/postgres/100/05_iam_grant.up.sql | 20 ++++++++++++------- internal/db/sqltest/tests/iam/iam_grant.sql | 12 +++++------ 2 files changed, 19 insertions(+), 13 deletions(-) diff --git a/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql b/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql index 5eca88e70d..edb3a60105 100644 --- a/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql @@ -3,11 +3,21 @@ begin; + -- Create the domain wt_canonical_grant to enforce the canonical grant format. + -- A canonical grant is a semicolon-separated list of key=value pairs. + -- e.g. "id=*;type=role;action=read;output_fields=id,name" + create domain wt_canonical_grant as text + check( + value ~ '^(?:[^;=]+=[^;=]+)(?:;[^;=]+=[^;=]+)*;?$' + ); + comment on domain wt_canonical_grant is + 'A canonical grant is a semicolon-separated list of key=value pairs.'; + -- iam_grant is the root table for a grant value object. -- A grant can only reference a single resource, including the special -- strings "*" to indicate "all" resources, and "unknown" when no resource is set. create table iam_grant ( - canonical_grant text primary key, + canonical_grant wt_canonical_grant primary key, resource text not null constraint iam_grant_resource_enm_fkey references iam_grant_resource_enm(name) @@ -20,15 +30,11 @@ begin; create index iam_grant_resource_ix on iam_grant (resource); + -- set_resource sets the resource column based on the "type" token in the canonical_grant. create or replace function set_resource() returns trigger as $$ declare type_matches text[]; begin - -- validate that every token is in the form key=value - if not new.canonical_grant ~ '^(?:[^;=]+=[^;=]+)(?:;[^;=]+=[^;=]+)*;?$' then - raise exception 'malformed grant: %', new.canonical_grant; - end if; - -- Extract all "type" tokens from the canonical_grant string select array_agg(t[1]) into type_matches @@ -47,7 +53,7 @@ begin; end $$ language plpgsql; comment on function set_resource() is - 'set_resource is a trigger function that validates the canonical grant string and sets the resource column based on the "type" token. Malformed tokens raise an exception. A valid grant without a type token results in resource being set to "unknown".'; + 'set_resource sets the resource column based on the "type" token. A valid grant without a type token results in resource being set to "unknown".'; create trigger set_resource before insert on iam_grant for each row execute procedure set_resource(); diff --git a/internal/db/sqltest/tests/iam/iam_grant.sql b/internal/db/sqltest/tests/iam/iam_grant.sql index 3d7db95b29..38ea923da7 100644 --- a/internal/db/sqltest/tests/iam/iam_grant.sql +++ b/internal/db/sqltest/tests/iam/iam_grant.sql @@ -30,7 +30,7 @@ prepare insert_malformed_grant as ('no_type_at_all;'); select throws_like( 'insert_malformed_grant', - 'malformed grant: no_type_at_all;', + 'value for domain wt_canonical_grant violates check constraint "wt_canonical_grant_check"', 'inserting a grant that is malformed should fail' ); @@ -178,7 +178,7 @@ prepare insert_grant_malformed_type_with_no_semicolon as ('ids=*;type=credential-library actions=create;output_fields=id'); select throws_like( 'insert_grant_malformed_type_with_no_semicolon', - 'malformed grant: ids=*;type=credential-library actions=create;output_fields=id', + 'value for domain wt_canonical_grant violates check constraint "wt_canonical_grant_check"', 'inserting a resource with a malformed type should fail' ); @@ -190,7 +190,7 @@ prepare insert_grant_malformed_type_with_no_equals as ('ids=*;type;actions=create;output_fields=id'); select throws_like( 'insert_grant_malformed_type_with_no_equals', - 'malformed grant: ids=*;type;actions=create;output_fields=id', + 'value for domain wt_canonical_grant violates check constraint "wt_canonical_grant_check"', 'inserting a resource with a malformed type should fail' ); @@ -202,7 +202,7 @@ prepare insert_grant_malformed_type_with_no_value as ('ids=*;type=;actions=create;output_fields=id'); select throws_like( 'insert_grant_malformed_type_with_no_value', - 'malformed grant: ids=*;type=;actions=create;output_fields=id', + 'value for domain wt_canonical_grant violates check constraint "wt_canonical_grant_check"', 'inserting a resource with a malformed type should fail' ); @@ -229,7 +229,7 @@ prepare insert_grant_malformed_type_with_double_ids_semicolon as ('ids=*;;type=credential-library;actions=create;output_fields=id'); select throws_like( 'insert_grant_malformed_type_with_double_ids_semicolon', - 'malformed grant: ids=*;;type=credential-library;actions=create;output_fields=id', + 'value for domain wt_canonical_grant violates check constraint "wt_canonical_grant_check"', 'inserting a resource with a malformed type should fail' ); @@ -256,7 +256,7 @@ prepare insert_grant_malformed_type_with_semicolon_after_type as ('ids=*;type;=credential-library;actions=create;output_fields=id;'); select throws_like( 'insert_grant_malformed_type_with_semicolon_after_type', - 'malformed grant: ids=*;type;=credential-library;actions=create;output_fields=id;', + 'value for domain wt_canonical_grant violates check constraint "wt_canonical_grant_check"', 'inserting a resource with a malformed type should fail' ); From c97fd7fd63fc93a3a92986a3cd98efbb8ecaae62 Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Mon, 3 Mar 2025 14:54:18 -0500 Subject: [PATCH 25/29] update wt_canonical_grant comment --- .../db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql | 2 +- 1 file changed, 1 insertion(+), 1 deletion(-) diff --git a/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql b/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql index edb3a60105..d7be50a4f8 100644 --- a/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql @@ -3,7 +3,7 @@ begin; - -- Create the domain wt_canonical_grant to enforce the canonical grant format. + -- wt_canonical_grant domain represents Boundary canonical grant. -- A canonical grant is a semicolon-separated list of key=value pairs. -- e.g. "id=*;type=role;action=read;output_fields=id,name" create domain wt_canonical_grant as text From 3fdcfa1640baeeee7d9bb12b63bf85b603df5989 Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Tue, 4 Mar 2025 15:13:16 -0500 Subject: [PATCH 26/29] address PR feedback on primary key and function name --- .../migrations/oss/postgres/100/01_iam_role_global.up.sql | 3 ++- .../schema/migrations/oss/postgres/100/02_iam_role_org.up.sql | 3 ++- .../db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql | 2 +- 3 files changed, 5 insertions(+), 3 deletions(-) diff --git a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql index 048383e47d..bf9a59ddc5 100644 --- a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql @@ -164,7 +164,8 @@ begin; references iam_role_global(public_id, grant_scope) on delete cascade on update cascade, - create_time wt_timestamp + create_time wt_timestamp, + primary key(role_id, scope_id) ); comment on table iam_role_global_individual_grant_scope is 'iam_role_global_individual_grant_scope is the subtype table for the global role with grant_scope as individual.'; diff --git a/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql b/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql index 053c89cb2e..90a7145632 100644 --- a/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql @@ -106,7 +106,8 @@ begin; references iam_role_org(public_id, grant_scope) on delete cascade on update cascade, - create_time wt_timestamp + create_time wt_timestamp, + primary key(role_id, scope_id) ); comment on table iam_role_org_individual_grant_scope is 'iam_role_global_individual_grant_scope is the subtype table for the org role with grant_scope as individual.'; diff --git a/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql b/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql index d7be50a4f8..2aae905c26 100644 --- a/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql @@ -31,7 +31,7 @@ begin; on iam_grant (resource); -- set_resource sets the resource column based on the "type" token in the canonical_grant. - create or replace function set_resource() returns trigger + create function set_resource() returns trigger as $$ declare type_matches text[]; begin From d998b2e1cf75417390024da82e3a298cde457bd6 Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Wed, 5 Mar 2025 12:09:31 -0500 Subject: [PATCH 27/29] fixup! update order of columns to match primary key --- .../oss/postgres/100/01_iam_role_global.up.sql | 18 +++++++++--------- .../oss/postgres/100/02_iam_role_org.up.sql | 10 +++++----- 2 files changed, 14 insertions(+), 14 deletions(-) diff --git a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql index bf9a59ddc5..65cf871461 100644 --- a/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/01_iam_role_global.up.sql @@ -140,6 +140,15 @@ begin; references iam_role_global(public_id) on delete cascade on update cascade, + scope_id wt_scope_id not null + constraint iam_scope_fkey + references iam_scope(public_id) + on delete cascade + on update cascade + constraint scope_id_is_not_global + check( + scope_id != 'global' + ), -- grant_scope is used for constraint checking. -- This restricts the grant_scope to be 'individual' -- and since it is also a foreign key to the iam_role_global @@ -150,15 +159,6 @@ begin; check( grant_scope = 'individual' ), - scope_id wt_scope_id not null - constraint iam_scope_fkey - references iam_scope(public_id) - on delete cascade - on update cascade - constraint scope_id_is_not_global - check( - scope_id != 'global' - ), constraint iam_role_global_grant_scope_fkey foreign key (role_id, grant_scope) references iam_role_global(public_id, grant_scope) diff --git a/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql b/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql index 90a7145632..a84d6cd38f 100644 --- a/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/02_iam_role_org.up.sql @@ -86,6 +86,11 @@ begin; references iam_role_org(public_id) on delete cascade on update cascade, + scope_id wt_scope_id not null + constraint iam_scope_org_scope_id_fkey + references iam_scope_project(scope_id) + on delete cascade + on update cascade, -- grant_scope is used for constraint checking. -- This restricts the grant_scope to be 'individual' -- and since it is also a foreign key to the iam_role_org @@ -96,11 +101,6 @@ begin; check( grant_scope = 'individual' ), - scope_id wt_scope_id not null - constraint iam_scope_org_scope_id_fkey - references iam_scope_project(scope_id) - on delete cascade - on update cascade, constraint iam_role_org_grant_scope_fkey foreign key (role_id, grant_scope) references iam_role_org(public_id, grant_scope) From e7d799578c2a2741305cd3cf525c2a98d698d432 Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Thu, 6 Mar 2025 16:58:02 -0500 Subject: [PATCH 28/29] update canonical_grant validation --- .../oss/postgres/100/05_iam_grant.up.sql | 20 +++++++-- .../db/sqltest/initdb.d/01_colors_persona.sql | 26 +++++------ .../sqltest/initdb.d/03_widgets_persona.sql | 16 +++---- internal/db/sqltest/tests/iam/iam_grant.sql | 44 +++++++++++++++---- 4 files changed, 72 insertions(+), 34 deletions(-) diff --git a/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql b/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql index 2aae905c26..c9822a8efe 100644 --- a/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql +++ b/internal/db/schema/migrations/oss/postgres/100/05_iam_grant.up.sql @@ -5,10 +5,10 @@ begin; -- wt_canonical_grant domain represents Boundary canonical grant. -- A canonical grant is a semicolon-separated list of key=value pairs. - -- e.g. "id=*;type=role;action=read;output_fields=id,name" + -- e.g. "ids=*;type=role;actions=read;output_fields=id,name" create domain wt_canonical_grant as text check( - value ~ '^(?:[^;=]+=[^;=]+)(?:;[^;=]+=[^;=]+)*;?$' + value ~ '^(?:[^;=]+=[^;=]+)(?:;[^;=]+=[^;=]+)*?$' ); comment on domain wt_canonical_grant is 'A canonical grant is a semicolon-separated list of key=value pairs.'; @@ -36,9 +36,21 @@ begin; declare type_matches text[]; begin -- Extract all "type" tokens from the canonical_grant string - select array_agg(t[1]) + with + parts (p) as ( + select p + from regexp_split_to_table(new.canonical_grant, ';') as p + ), + kv (k, v) as ( + select part[1] as k, + part[2] as v + from parts, + regexp_split_to_array(parts.p, '=') as part + ) + select array_agg(v) into type_matches - from regexp_matches(new.canonical_grant, '(?<=^|;)type=([^;]+)(?=;|$)', 'g') as t; + from kv + where k = 'type'; -- if there are multiple canonical grant types specified, throw an error. -- Ensure that the canonical_grant type is only referencing a single resource diff --git a/internal/db/sqltest/initdb.d/01_colors_persona.sql b/internal/db/sqltest/initdb.d/01_colors_persona.sql index f6cd09154d..f767decc63 100644 --- a/internal/db/sqltest/initdb.d/01_colors_persona.sql +++ b/internal/db/sqltest/initdb.d/01_colors_persona.sql @@ -135,19 +135,19 @@ begin; ('r_gg____shop', 'global'); insert into iam_role_grant - (role_id, canonical_grant, raw_grant) - values - ('r_gg_____buy', 'type=*;actions=update', 'type=*;actions=update'), - ('r_gg____shop', 'type=*;actions=read', 'type=*;actions=read'), - ('r_go____name', 'type=group;action=create,update,read,list', 'type=group;action=create,update,read,'), - ('r_gp____spec', 'type=group;action=delete', 'type=group;action=delete'), - ('r_oo_____art', 'type=group;action=create', 'type=group;action=create'), - ('r_op_bc__art', 'type=group;action=create', 'type=group;action=create'), - ('r_op_rc__art', 'type=group;action=create', 'type=group;action=create'), - ('r_op_gc__art', 'type=group;action=create', 'type=group;action=create'), - ('r_pp_bc__mix', 'type=group;action=add-members', 'type=group;action=add-members'), - ('r_pp_rc__mix', 'type=group;action=set-members', 'type=group;action=set-members'), - ('r_pp_gc__mix', 'type=group;action=delete-members', 'type=group;action=delete-members'); + (role_id, canonical_grant, raw_grant) + values + ('r_gg_____buy', 'ids=*;type=*;actions=update', 'ids=*;type=*;actions=update'), + ('r_gg____shop', 'ids=*;type=*;actions=read;output_fields=id', 'ids=*;type=*;actions=read;output_fields=id'), + ('r_go____name', 'ids=*;type=group;actions=create,update,read,list', 'ids=*;type=group;actions=create,update,read,'), + ('r_gp____spec', 'ids=*;type=group;actions=delete', 'ids=*;type=group;actions=delete'), + ('r_oo_____art', 'ids=*;type=group;actions=create', 'ids=*;type=group;actions=create'), + ('r_op_bc__art', 'ids=*;type=auth-token;actions=create', 'ids=*;type=auth-token;actions=create'), + ('r_op_rc__art', 'ids=*;type=target;actions=create', 'ids=*;type=targets;actions=create'), + ('r_op_gc__art', 'ids=*;type=auth-method;actions=authenticate', 'ids=*;type=auth-method;actions=create'), + ('r_pp_bc__mix', 'ids=*;type=group;actions=add-members', 'ids=*;type=group;actions=add-members'), + ('r_pp_rc__mix', 'ids=*;type=group;actions=set-members', 'ids=*;type=group;actions=set-members'), + ('r_pp_gc__mix', 'ids=*;type=group;actions=delete-members', 'ids=*;type=group;actions=delete-members'); insert into iam_group_role (role_id, principal_id) diff --git a/internal/db/sqltest/initdb.d/03_widgets_persona.sql b/internal/db/sqltest/initdb.d/03_widgets_persona.sql index 463884a5fc..9af98ac149 100644 --- a/internal/db/sqltest/initdb.d/03_widgets_persona.sql +++ b/internal/db/sqltest/initdb.d/03_widgets_persona.sql @@ -77,14 +77,14 @@ begin; insert into iam_role_grant (role_id, canonical_grant, raw_grant) values - -- ('r_gg_____buy', 'type=*;action=purchase', 'purchase anything'), - -- ('r_gg____shop', 'type=*;action=view', 'view anything'), - ('r_oo_____eng', 'type=target;action=create,update,authorize-session', 'type=target;action=create,update,authorize-session'), - ('r_op_sw__eng', 'type=target;action=add-credential-sources,remove-credential-sources,set-credential-sources', 'type=target;action=add-credential-sources,remove-credential-sources,set-credential-sources'), - ('r_op_sw__eng', 'type=target;action=add-host-sources,remove-host-sources,set-host-sources', 'type=target;action=add-host-sources,remove-host-sources,set-host-sources'), - ('r_op_sw__eng', 'type=target;action=read,list', 'type=target;action=read,list'), - ('r_pp_bw__bld', 'type=target;action=create,delete', 'type=target;action=create,delete'), - ('r_pp_sw__bld', 'type=target;action=authorize-session', 'type=target;action=authorize-session'); + -- ('r_gg_____buy', 'type=*;actions=purchase', 'purchase anything'), + -- ('r_gg____shop', 'type=*;actions=view', 'view anything'), + ('r_oo_____eng', 'ids=*;type=alias;actions=create,update', 'ids=*;type=alias;actions=create,update'), + ('r_op_sw__eng', 'ids=*;type=target;actions=add-credential-sources,remove-credential-sources,set-credential-sources', 'ids=*;type=target;actions=add-credential-sources,remove-credential-sources,set-credential-source'), + ('r_op_sw__eng', 'ids=*;type=target;actions=add-host-sources,remove-host-sources,set-host-sources', 'ids=*;type=target;actions=add-host-sources,remove-host-sources,set-host-sources'), + ('r_op_sw__eng', 'ids=*;type=host-catalog;actions=read,list', 'ids=*;type=host-catalog;actions=read,list'), + ('r_pp_bw__bld', 'ids=*;type=credential-library;actions=create,delete', 'ids=*;type=credential-library;actions=create,delete'), + ('r_pp_sw__bld', 'ids=*;type=scope;actions=no-op,list', 'ids=*;type=scope;actions=no-op,list'); insert into iam_group_role (role_id, principal_id) diff --git a/internal/db/sqltest/tests/iam/iam_grant.sql b/internal/db/sqltest/tests/iam/iam_grant.sql index 38ea923da7..59e2d549e3 100644 --- a/internal/db/sqltest/tests/iam/iam_grant.sql +++ b/internal/db/sqltest/tests/iam/iam_grant.sql @@ -2,7 +2,7 @@ -- SPDX-License-Identifier: BUSL-1.1 begin; -select plan(27); +select plan(29); select wtt_load('widgets', 'iam'); -- insert canonical_grant with valid resource @@ -11,36 +11,49 @@ prepare insert_grant_scope as insert into iam_grant (canonical_grant) values - ('type=scope;others=stuff;'); + ('type=scope;others=stuff'); select lives_ok('insert_grant_scope'); select is( (select resource from iam_grant - where canonical_grant = 'type=scope;others=stuff;'), + where canonical_grant = 'type=scope;others=stuff'), 'scope', 'resource should be set to "scope" by set_resource() trigger' ); --- insert canonical_grant with no type --- the insert should fail because the type is malformed +-- insert invalid canonical_grant which does not match the wt_canonical_grant domain +-- the insert should fail because the canonical_grant is malformed prepare insert_malformed_grant as insert into iam_grant (canonical_grant) values - ('no_type_at_all;'); + ('no_type_at_all'); select throws_like( 'insert_malformed_grant', 'value for domain wt_canonical_grant violates check constraint "wt_canonical_grant_check"', 'inserting a grant that is malformed should fail' ); +-- insert invalid canonical_grant with trailing semicolon +-- the insert should fail because the the canonical_grant has a trailing semicolon +prepare insert_grant_with_trailing_semicolon as + insert into iam_grant + (canonical_grant) + values + ('ids=*;type=role;actions=*;'); +select throws_like( + 'insert_grant_with_trailing_semicolon', + 'value for domain wt_canonical_grant violates check constraint "wt_canonical_grant_check"', + 'inserting a grant with trailing semicolon should fail' +); + -- insert canonical_grant with type=role,group --- validate the resource is set to 'role' +-- the insert should fail because the resource is not a single value prepare insert_grant_role as insert into iam_grant (canonical_grant) values - ('type=role,group;foo=bar;'); + ('type=role,group;foo=bar'); select throws_like( 'insert_grant_role', 'insert or update on table "iam_grant" violates foreign key constraint "iam_grant_resource_enm_fkey"', @@ -53,13 +66,26 @@ prepare insert_grant_bogus as insert into iam_grant (canonical_grant) values - ('type=bogus;some=thing;'); + ('type=bogus;some=thing'); select throws_like( 'insert_grant_bogus', 'insert or update on table "iam_grant" violates foreign key constraint "iam_grant_resource_enm_fkey"', 'inserting a resource not in iam_grant_resource_enm should fail' ); +-- the set_resource() trigger will set resource='bogus', but we did not insert 'bogus' +-- into resource_enm, so it should fail. +prepare insert_grant_bogus_with_action as + insert into iam_grant + (canonical_grant) + values + ('type=bogus;actions=create'); +select throws_like( + 'insert_grant_bogus_with_action', + 'insert or update on table "iam_grant" violates foreign key constraint "iam_grant_resource_enm_fkey"', + 'inserting a resource not in iam_grant_resource_enm should fail' +); + -- insert a duplicate canonical_grant -- validate that the primary key constraint is enforced prepare insert_dup_grant_1 as From 89ecf226baac38c0cc2a21fc8fa7cb3fac9fa711 Mon Sep 17 00:00:00 2001 From: Elim Tsiagbey Date: Mon, 10 Mar 2025 10:23:16 -0400 Subject: [PATCH 29/29] remove commented out role --- internal/db/sqltest/initdb.d/03_widgets_persona.sql | 2 -- 1 file changed, 2 deletions(-) diff --git a/internal/db/sqltest/initdb.d/03_widgets_persona.sql b/internal/db/sqltest/initdb.d/03_widgets_persona.sql index 9af98ac149..5d536174df 100644 --- a/internal/db/sqltest/initdb.d/03_widgets_persona.sql +++ b/internal/db/sqltest/initdb.d/03_widgets_persona.sql @@ -77,8 +77,6 @@ begin; insert into iam_role_grant (role_id, canonical_grant, raw_grant) values - -- ('r_gg_____buy', 'type=*;actions=purchase', 'purchase anything'), - -- ('r_gg____shop', 'type=*;actions=view', 'view anything'), ('r_oo_____eng', 'ids=*;type=alias;actions=create,update', 'ids=*;type=alias;actions=create,update'), ('r_op_sw__eng', 'ids=*;type=target;actions=add-credential-sources,remove-credential-sources,set-credential-sources', 'ids=*;type=target;actions=add-credential-sources,remove-credential-sources,set-credential-source'), ('r_op_sw__eng', 'ids=*;type=target;actions=add-host-sources,remove-host-sources,set-host-sources', 'ids=*;type=target;actions=add-host-sources,remove-host-sources,set-host-sources'),