diff --git a/internal/db/schema/migrations/oss/postgres/101/01_app_token_base.up.sql b/internal/db/schema/migrations/oss/postgres/101/01_app_token_base.up.sql new file mode 100644 index 0000000000..412280d640 --- /dev/null +++ b/internal/db/schema/migrations/oss/postgres/101/01_app_token_base.up.sql @@ -0,0 +1,246 @@ +-- Copyright (c) HashiCorp, Inc. +-- SPDX-License-Identifier: BUSL-1.1 + +begin; + + + -- Create the enumeration table for app token global grant scope + create table app_token_global_grant_scope_enm ( + name text primary key + constraint only_predefined_app_token_global_grant_scope_allowed + check( + name in ( + 'individual', + 'children', + 'descendants' + ) + ) + ); + comment on table app_token_global_grant_scope_enm is + 'app_token_global_grant_scope_enm is an enumeration table for app token global grant scope types.'; + + -- Insert the predefined app token global grant scopes + insert into app_token_global_grant_scope_enm (name) + values + ('individual'), + ('children'), + ('descendants'); + + -- Create the enumeration table for app token org grant scope + create table app_token_org_grant_scope_enm ( + name text primary key + constraint only_predefined_app_token_org_grant_scope_allowed + check( + name in ( + 'individual', + 'children' + ) + ) + ); + comment on table app_token_org_grant_scope_enm is + 'app_token_org_grant_scope_enm is an enumeration table for app token org grant scope types.'; + + -- Insert the predefined app token org grant scopes + insert into app_token_org_grant_scope_enm (name) + values + ('individual'), + ('children'); + + + create table app_token ( + public_id wt_public_id primary key, + scope_id wt_scope_id not null + constraint iam_scope_fkey + references iam_scope(public_id) + on delete cascade + on update cascade, + create_time wt_timestamp, + update_time wt_timestamp, + approximate_last_access_time wt_timestamp, + expiration_time wt_timestamp, + time_to_stale_seconds integer not null default 0 + constraint time_to_stale_seconds_must_be_non_negative + check(time_to_stale_seconds >= 0) + ); + comment on table app_token is + 'app_token is the base table for application tokens that can be scoped to global, org, or project levels.'; + + create trigger immutable_columns before update on app_token + for each row execute procedure immutable_columns('public_id', 'create_time', 'scope_id', 'expiration_time', 'time_to_stale_seconds'); + + create function insert_app_token_subtype() returns trigger + as $$ + begin + insert into app_token + (public_id, scope_id, expiration_time, time_to_stale_seconds) + values + (new.public_id, new.scope_id, new.expiration_time, new.time_to_stale_seconds); + return new; + end; + $$ language plpgsql; + comment on function insert_app_token_subtype() is + 'insert_app_token_subtype is used to automatically insert a row into the app_token table ' + 'whenever a row is inserted into the subtype table'; + +-- Add trigger to update the new update_time column on every app_token subtype update. + create function update_app_token_table_update_time() returns trigger + as $$ + begin + update app_token + set update_time = new.update_time + where public_id = new.public_id; + return new; + end; + $$ language plpgsql; + comment on function update_app_token_table_update_time() is + 'update_app_token_table_update_time is used to automatically update the update_time ' + 'of the base table whenever one of the subtype app_token tables are updated'; + +-- Add trigger to update the new approximate_last_access_time column on every app_token subtype update. + create function update_app_token_table_approximate_last_access_time() returns trigger + as $$ + begin + -- Only update if approximate_last_access_time has actually changed + if old.approximate_last_access_time is distinct from new.approximate_last_access_time then + update app_token + set approximate_last_access_time = new.approximate_last_access_time + where public_id = new.public_id; + end if; + return new; + end; + $$ language plpgsql; + comment on function update_app_token_table_approximate_last_access_time() is + 'update_app_token_table_approximate_last_access_time is used to automatically update the approximate_last_access_time ' + 'of the base table whenever one of the subtype app_token tables are updated'; + + -- Function to validate that created_by_user_id exists in iam_user + create or replace function validate_app_token_created_by_user() returns trigger + as $$ + begin + perform 1 + from iam_user + where public_id = new.created_by_user_id; + if not found then + raise exception 'User ID % does not exist in iam_user', new.created_by_user_id; + end if; + return new; + end; + $$ language plpgsql; + comment on function validate_app_token_created_by_user() is + 'validate_app_token_created_by_user is used to enforce that created_by_user_id exists in iam_user table'; + + -- Function to validate that revoked can only be updated from false to true + create or replace function validate_app_token_revocation() returns trigger + as $$ + begin + -- For updates, check revoked field changes + if old.revoked is distinct from new.revoked then + -- Only allow change from false to true + if not (old.revoked = false and new.revoked = true) then + raise exception 'App token cannot be unrevoked. revoked value. Current: %, Attempted: %', + old.revoked, new.revoked; + end if; + end if; + + return new; + end; + $$ language plpgsql; + comment on function validate_app_token_revocation() is + 'validate_app_token_revocation ensures that the revoked field can only be updated from false to true, ' + 'preventing tokens from being un-revoked or other invalid state transitions'; + + -- App token deleted tracking table + create table app_token_deleted ( + public_id wt_public_id primary key, + delete_time wt_timestamp not null + ); + comment on table app_token_deleted is + 'app_token_deleted holds the ID and delete_time of every deleted app token. ' + 'It is automatically trimmed of records older than 30 days by a job.'; + + -- Create trigger for app_token deletion tracking + create trigger insert_deleted_id after delete on app_token + for each row execute function insert_deleted_id('app_token_deleted'); + + -- Create index on delete_time for app_token_deleted + create index app_token_deleted_delete_time_idx on app_token_deleted (delete_time); + + create table app_token_permission ( + private_id wt_private_id primary key, + app_token_id wt_public_id not null, + constraint app_token_permission_app_token_id_idx + foreign key (app_token_id) references app_token(public_id) + on delete cascade + on update cascade + ); + comment on table app_token_permission is + 'app_token_permission is the base table for application token permissions.'; + + -- Create index on app_token_id for efficient token-based lookups + create index app_token_permission_app_token_id_idx on app_token_permission (app_token_id); + + create function insert_app_token_permission_subtype() returns trigger + as $$ + begin + insert into app_token_permission + (private_id, app_token_id) + values + (new.private_id, new.app_token_id); + return new; + end; + $$ language plpgsql; + comment on function insert_app_token_permission_subtype() is + 'insert_app_token_permission_subtype is used to automatically insert a row into the app_token_permission table ' + 'whenever a row is inserted into the subtype table'; + + create table app_token_permission_grant ( + permission_id wt_private_id + constraint app_token_permission_grant_fkey + references app_token_permission(private_id) + on delete cascade + on update cascade, + canonical_grant wt_canonical_grant not null + constraint app_token_permission_iam_grant_fkey + references iam_grant(canonical_grant) + on delete cascade + on update cascade, + raw_grant text not null + constraint raw_grant_must_not_be_empty + check( + length(trim(raw_grant)) > 0 + ), + primary key(permission_id, canonical_grant) + ); + comment on table app_token_permission_grant is + 'app_token_permission_grant contains grants assigned to app tokens in project scope'; + + create trigger upsert_canonical_grant_trigger before insert on app_token_permission_grant + for each row execute procedure upsert_canonical_grant(); + + create table app_token_cipher ( + app_token_id wt_public_id primary key + constraint app_token_cipher_app_token_fkey + references app_token(public_id) + on delete cascade + on update cascade, + key_id text not null + constraint kms_data_key_version_fkey + references kms_data_key_version (private_id) + on delete restrict + on update cascade, + token bytea not null unique + ); + comment on table app_token_cipher is + 'app_token_cipher is the table for application token encryption keys. ' + 'This was split out from the app_token table to avoid re-encrypting tokens when tokens are no longer valid. ' + 'When an app token becomes invalid, the associated row in this table may be deleted.'; + + -- Add oplog entries for tracking changes (similar to IAM role tables) + insert into oplog_ticket (name, version) + values + ('app_token', 1), + ('app_token_global', 1), + ('app_token_org', 1), + ('app_token_project', 1); + +commit; \ No newline at end of file diff --git a/internal/db/schema/migrations/oss/postgres/101/02_app_token_global.up.sql b/internal/db/schema/migrations/oss/postgres/101/02_app_token_global.up.sql new file mode 100644 index 0000000000..fdccde01bf --- /dev/null +++ b/internal/db/schema/migrations/oss/postgres/101/02_app_token_global.up.sql @@ -0,0 +1,220 @@ +-- Copyright (c) HashiCorp, Inc. +-- SPDX-License-Identifier: BUSL-1.1 +begin; + + -- Main app_token table similar to iam_role structure + create table app_token_global ( + public_id wt_public_id primary key + constraint app_token_fkey + references app_token(public_id) + on delete cascade + on update cascade, + scope_id wt_scope_id not null + constraint iam_scope_global_scope_id_fkey + references iam_scope_global(scope_id) + on delete cascade + on update cascade, + name text, + description text, + revoked boolean not null default false, + create_time wt_timestamp, + update_time wt_timestamp, + created_by_user_id wt_user_id not null, + approximate_last_access_time wt_timestamp + constraint last_access_time_must_not_be_after_expiration_time + check( + approximate_last_access_time <= expiration_time + ), + time_to_stale_seconds integer not null default 0 + constraint time_to_stale_seconds_must_be_non_negative + check(time_to_stale_seconds >= 0), + expiration_time wt_timestamp + constraint create_time_must_not_be_after_expiration_time + check( + create_time <= expiration_time + ), + constraint app_token_global_name_scope_id_uq + unique(name, scope_id) + ); + comment on table app_token_global is + 'app_token_global is the table for application tokens in global scope'; + + create trigger default_create_time_column before insert on app_token_global + for each row execute procedure default_create_time(); + + create trigger update_time_column before update on app_token_global + for each row execute procedure update_time_column(); + + create trigger revocation_check before update on app_token_global + for each row execute procedure validate_app_token_revocation(); + + create trigger approximate_last_access_time_column before update on app_token_global + for each row execute procedure update_app_token_table_approximate_last_access_time(); + + create trigger immutable_columns before update on app_token_global + for each row execute procedure immutable_columns('public_id', 'create_time', 'scope_id', 'created_by_user_id', 'expiration_time', 'time_to_stale_seconds'); + + create trigger insert_app_token_subtype before insert on app_token_global + for each row execute procedure insert_app_token_subtype(); + + create trigger validate_app_token_global_created_by_user_trigger before insert on app_token_global + for each row execute function validate_app_token_created_by_user(); + + -- App token permissions global table + create table app_token_permission_global ( + private_id wt_private_id + constraint app_token_permission_global_fkey + references app_token_permission(private_id) + on delete cascade + on update cascade + primary key, + app_token_id wt_public_id + constraint app_token_global_fkey + references app_token_global(public_id) + on delete cascade + on update cascade, + description text, + grant_this_scope boolean not null default false, + grant_scope text not null + constraint app_token_global_grant_scope_enm_fkey + references app_token_global_grant_scope_enm(name) + on delete restrict + on update cascade, + create_time wt_timestamp, + constraint app_token_permission_global_grant_scope_private_id_uq + unique(grant_scope, private_id) + ); + comment on table app_token_permission_global is + 'app_token_permission_global contains global scope-specific permissions for app tokens.'; + + -- Create index on app_token_id for better query performance + create index app_token_permission_global_app_token_id_idx on app_token_permission_global (app_token_id); + + -- Add triggers for app_token_permission_global + create trigger default_create_time_column before insert on app_token_permission_global + for each row execute procedure default_create_time(); + + create trigger immutable_columns before update on app_token_permission_global + for each row execute procedure immutable_columns('app_token_id', 'scope_id', 'label', 'grant_scope', 'grant_this_scope', 'create_time'); + + create trigger insert_app_token_permission_subtype before insert on app_token_permission_global + for each row execute procedure insert_app_token_permission_subtype(); + + create table app_token_permission_global_individual_org_grant_scope ( + permission_id wt_private_id + constraint app_token_permission_global_fkey + references app_token_permission_global(private_id) + on delete cascade + on update cascade, + scope_id wt_scope_id not null, + -- 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 app_token_permission_global + -- grant_scope, it ensures that app_token_permission_global is set to 'individual' + -- if this table is populated for the corresponding permission. + grant_scope text not null + constraint only_individual_grant_scope_allowed + check( + grant_scope = 'individual' + ), + create_time wt_timestamp, + constraint app_token_permission_global_grant_scope_fkey + foreign key (grant_scope, permission_id) + references app_token_permission_global(grant_scope, private_id) + on delete cascade + on update cascade, + primary key(permission_id, scope_id) + ); + comment on table app_token_permission_global_individual_org_grant_scope is + 'app_token_permission_global_individual_org_grant_scope is a list of individually granted org scope to global app token permissions with grant_scope of individual.'; + + create or replace function validate_global_permission_org_scope() returns trigger + as $$ + begin + perform + from iam_scope_org + where iam_scope_org.scope_id = new.scope_id; + if not found then + raise exception 'org scope_id % not found', new.scope_id; + end if; + return new; + end; + $$ language plpgsql; + comment on function validate_global_permission_org_scope() is + 'validate_global_permission_org_scope is used to enforced that scope ID added to app_token_permission_global_individual_project_grant_scope' + 'exists and is an org scope'; + + -- Add trigger for app_token_permission_global_individual_org_grant_scope + create trigger default_create_time_column before insert on app_token_permission_global_individual_org_grant_scope + for each row execute procedure default_create_time(); + + create trigger immutable_columns before update on app_token_permission_global_individual_org_grant_scope + for each row execute procedure immutable_columns('scope_id', 'grant_scope', 'create_time'); + + -- Trigger to validate org scope exists + create trigger validate_global_permission_org_scope_trigger before insert on app_token_permission_global_individual_org_grant_scope + for each row execute function validate_global_permission_org_scope(); + + create table app_token_permission_global_individual_project_grant_scope ( + permission_id wt_private_id + constraint app_token_permission_global_fkey + references app_token_permission_global(private_id) + on delete cascade + on update cascade, + -- scope_id does not have a foreign key constraint to iam_scope_project + -- because we do not want to enforce that the project must exist + -- the project may be deleted but that should not affect the app token permission grant scopes + -- the application layer will query the DB to check if the project exists and makes appropriate decisions + scope_id wt_scope_id not null, + -- 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 app_token_permission_global + -- grant_scope, it ensures that app_token_permission_global is set to 'individual' + -- if this table is populated for the corresponding permission. + -- both children and individual are allowed for this global permission + -- because projects can be individually in addition to children + -- which grants all orgs + grant_scope text not null + constraint only_individual_grant_scope_allowed + check( + grant_scope in ('individual', 'children') + ), + create_time wt_timestamp, + constraint app_token_permission_global_grant_scope_fkey + foreign key (grant_scope, permission_id) + references app_token_permission_global(grant_scope, private_id) + on delete cascade + on update cascade, + primary key(permission_id, scope_id) + ); + comment on table app_token_permission_global_individual_project_grant_scope is + 'app_token_permission_global_individual_project_grant_scope is a list of individually granted project scope table to global app token permissions with grant_scope of individual or children.'; + + create or replace function validate_global_permission_project_scope() returns trigger + as $$ + begin + perform + from iam_scope_project + where iam_scope_project.scope_id = new.scope_id; + if not found then + raise exception 'project scope_id % not found', new.scope_id; + end if; + return new; + end; + $$ language plpgsql; + comment on function validate_global_permission_project_scope() is + 'validate_global_permission_project_scope is used to enforced that scope ID added to app_token_permission_global_individual_project_grant_scope' + 'exists and is a project scope'; + + -- Add trigger for app_token_permission_global_individual_project_grant_scope + create trigger default_create_time_column before insert on app_token_permission_global_individual_project_grant_scope + for each row execute procedure default_create_time(); + + create trigger immutable_columns before update on app_token_permission_global_individual_project_grant_scope + for each row execute procedure immutable_columns('scope_id', 'grant_scope', 'create_time'); + + -- Trigger to validate project scope exists + create trigger validate_global_permission_project_scope_trigger before insert on app_token_permission_global_individual_project_grant_scope + for each row execute function validate_global_permission_project_scope(); + +commit; \ No newline at end of file diff --git a/internal/db/schema/migrations/oss/postgres/101/03_app_token_org.up.sql b/internal/db/schema/migrations/oss/postgres/101/03_app_token_org.up.sql new file mode 100644 index 0000000000..2eec34b86b --- /dev/null +++ b/internal/db/schema/migrations/oss/postgres/101/03_app_token_org.up.sql @@ -0,0 +1,180 @@ +-- Copyright (c) HashiCorp, Inc. +-- SPDX-License-Identifier: BUSL-1.1 +begin; + + -- Main app_token table similar to iam_role structure + create table app_token_org ( + public_id wt_public_id primary key + constraint app_token_fkey + references app_token(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_org(scope_id) + on delete cascade + on update cascade, + name text, + description text, + revoked boolean not null default false, + create_time wt_timestamp, + update_time wt_timestamp, + created_by_user_id wt_user_id not null, + approximate_last_access_time wt_timestamp + constraint last_access_time_must_not_be_after_expiration_time + check( + approximate_last_access_time <= expiration_time + ), + time_to_stale_seconds integer not null default 0 + constraint time_to_stale_seconds_must_be_non_negative + check(time_to_stale_seconds >= 0), + expiration_time wt_timestamp + constraint create_time_must_not_be_after_expiration_time + check( + create_time <= expiration_time + ), + constraint app_token_org_name_scope_id_uq + unique(name, scope_id) + ); + comment on table app_token_org is + 'app_token_org is the table for application tokens in org scope'; + + -- Add triggers for app_token + create trigger default_create_time_column before insert on app_token_org + for each row execute procedure default_create_time(); + + create trigger update_time_column before update on app_token_org + for each row execute procedure update_time_column(); + + create trigger revocation_check before update on app_token_org + for each row execute procedure validate_app_token_revocation(); + + create trigger approximate_last_access_time_column before update on app_token_org + for each row execute procedure update_app_token_table_approximate_last_access_time(); + + create trigger immutable_columns before update on app_token_org + for each row execute procedure immutable_columns('public_id', 'create_time', 'scope_id', 'created_by_user_id', 'expiration_time', 'time_to_stale_seconds'); + + create trigger insert_app_token_subtype before insert on app_token_org + for each row execute procedure insert_app_token_subtype(); + + create trigger validate_app_token_global_created_by_user_trigger before insert on app_token_org + for each row execute function validate_app_token_created_by_user(); + + -- App token permissions org table + create table app_token_permission_org ( + private_id wt_private_id + constraint app_token_permission_org_fkey + references app_token_permission(private_id) + on delete cascade + on update cascade + primary key, + app_token_id wt_public_id + constraint app_token_permission_fkey + references app_token_org(public_id) + on delete cascade + on update cascade, + description text, + grant_this_scope boolean not null default false, + grant_scope text not null + constraint app_token_org_grant_scope_enm_fkey + references app_token_org_grant_scope_enm(name) + on delete restrict + on update cascade, + create_time wt_timestamp, + -- Ensure this org permission belongs to the same app token as the base permission + constraint app_token_permission_org_grant_scope_public_id_uq + unique(grant_scope, private_id) + ); + comment on table app_token_permission_org is + 'app_token_permission_org is a subtype table of the app_token_permission table. It is used to store permissions that are scoped to an org.'; + + -- Create index on app_token_id for better query performance + create index app_token_permission_org_app_token_id_idx on app_token_permission_org (app_token_id); + + -- Add triggers for app_token_permission_org + create trigger default_create_time_column before insert on app_token_permission_org + for each row execute procedure default_create_time(); + + create trigger update_time_column before update on app_token_permission_org + for each row execute procedure update_time_column(); + + create trigger immutable_columns before update on app_token_permission_org + for each row execute procedure immutable_columns('app_token_id', 'scope_id', 'label', 'grant_this_scope', 'grant_scope', 'create_time'); + + create trigger insert_app_token_permission_subtype before insert on app_token_permission_org + for each row execute procedure insert_app_token_permission_subtype(); + + + create table app_token_permission_org_individual_grant_scope ( + permission_id wt_private_id + constraint app_token_permission_org_fkey + references app_token_permission_org(private_id) + on delete cascade + on update cascade, + scope_id wt_scope_id not null, + -- 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 app_token_permission_org + -- grant_scope, it ensures that app_token_permission_org is set to 'individual' + -- if this table is populated for the corresponding permission. + grant_scope text not null + constraint only_individual_grant_scope_allowed + check( + grant_scope = 'individual' + ), + constraint app_token_permission_org_grant_scope_fkey + foreign key (grant_scope, permission_id) + references app_token_permission_org(grant_scope, private_id) + on delete cascade + on update cascade, + create_time wt_timestamp, + primary key(permission_id, scope_id) + ); + comment on table app_token_permission_org_individual_grant_scope is + 'app_token_permission_org_individual_grant_scope is a list of individually granted project scope to org app token permissions with grant_scope of individual'; + + create function validate_org_permission_project_scope_and_parent() returns trigger + as $$ + declare + org_scope_id wt_scope_id; + begin + -- First get the org scope_id for this permission + select app_token_org.scope_id + into org_scope_id + from app_token_permission_org + join app_token_org + on app_token_org.public_id = app_token_permission_org.app_token_id + where app_token_permission_org.private_id = new.permission_id; + + if not found then + raise exception 'permission_id % not found or has no associated app token', new.permission_id; + end if; + + -- Then validate that the project exists and belongs to this org + perform + from iam_scope_project + where iam_scope_project.scope_id = new.scope_id + and iam_scope_project.parent_id = org_scope_id; + + if not found then + raise exception 'project scope_id % not found or is not a child of org %', new.scope_id, org_scope_id; + end if; + + return new; + end; + $$ language plpgsql; comment on function validate_org_permission_project_scope_and_parent() is + 'validate_org_permission_project_scope_and_parent ensures the project exists and belongs to the org of the token scope.'; + + -- Add trigger for app_token_permission_org_individual_grant_scope + create trigger default_create_time_column before insert on app_token_permission_org_individual_grant_scope + for each row execute procedure default_create_time(); + + create trigger immutable_columns before update on app_token_permission_org_individual_grant_scope + for each row execute procedure immutable_columns('app_token_id', 'scope_id', 'grant_scope', 'create_time'); + + -- Trigger to validate project scope relationship + create trigger validate_org_permission_project_scope_and_parent_trigger before insert on app_token_permission_org_individual_grant_scope + for each row execute function validate_org_permission_project_scope_and_parent(); + +commit; \ No newline at end of file diff --git a/internal/db/schema/migrations/oss/postgres/101/04_app_token_project.up.sql b/internal/db/schema/migrations/oss/postgres/101/04_app_token_project.up.sql new file mode 100644 index 0000000000..700bc986d2 --- /dev/null +++ b/internal/db/schema/migrations/oss/postgres/101/04_app_token_project.up.sql @@ -0,0 +1,100 @@ +-- Copyright (c) HashiCorp, Inc. +-- SPDX-License-Identifier: BUSL-1.1 +begin; + + -- Main app_token table similar to iam_role structure + create table app_token_project ( + public_id wt_public_id primary key + constraint app_token_fkey + references app_token(public_id) + on delete cascade + on update cascade, + scope_id wt_scope_id not null + constraint iam_scope_project_scope_id_fkey + references iam_scope_project(scope_id) + on delete cascade + on update cascade, + name text, + description text, + revoked boolean not null default false, + create_time wt_timestamp, + update_time wt_timestamp, + created_by_user_id wt_user_id not null, + approximate_last_access_time wt_timestamp + constraint last_access_time_must_not_be_after_expiration_time + check( + approximate_last_access_time <= expiration_time + ), + time_to_stale_seconds integer not null default 0 + constraint time_to_stale_seconds_must_be_non_negative + check(time_to_stale_seconds >= 0), + expiration_time wt_timestamp + constraint create_time_must_not_be_after_expiration_time + check( + create_time <= expiration_time + ), + constraint app_token_project_name_scope_id_uq + unique(name, scope_id) + ); + comment on table app_token_project is + 'app_token_project is the table for application tokens in project scope'; + + -- Add triggers for app_token + create trigger default_create_time_column before insert on app_token_project + for each row execute procedure default_create_time(); + + create trigger update_time_column before update on app_token_project + for each row execute procedure update_time_column(); + + create trigger revocation_check before update on app_token_project + for each row execute procedure validate_app_token_revocation(); + + create trigger approximate_last_access_time_column before update on app_token_project + for each row execute procedure update_app_token_table_approximate_last_access_time(); + + create trigger immutable_columns before update on app_token_project + for each row execute procedure immutable_columns('public_id', 'create_time', 'scope_id', 'created_by_user_id', 'expiration_time', 'time_to_stale_seconds'); + + create trigger insert_app_token_subtype before insert on app_token_project + for each row execute procedure insert_app_token_subtype(); + + create trigger validate_app_token_global_created_by_user_trigger before insert on app_token_project + for each row execute function validate_app_token_created_by_user(); + + -- App token permissions project table + create table app_token_permission_project ( + private_id wt_private_id + constraint app_token_permission_project_fkey + references app_token_permission(private_id) + on delete cascade + on update cascade + primary key, + app_token_id wt_public_id + constraint app_token_permission_fkey + references app_token_project(public_id) + on delete cascade + on update cascade, + description text, + grant_this_scope boolean not null default false, + create_time wt_timestamp + ); + comment on table app_token_permission_project is + 'app_token_permission_project is a subtype table of the app_token_permission table. It is used to store permissions that are scoped to a project.'; + + -- Create index on app_token_id for better query performance + create index app_token_permission_project_app_token_id_idx on app_token_permission_project (app_token_id); + + -- Add triggers for app_token_permission_project + create trigger default_create_time_column before insert on app_token_permission_project + for each row execute procedure default_create_time(); + + create trigger update_time_column before update on app_token_permission_project + for each row execute procedure update_time_column(); + + create trigger immutable_columns before update on app_token_permission_project + for each row execute procedure immutable_columns('app_token_id', 'scope_id', 'label', 'grant_this_scope', 'grant_scope', 'create_time'); + + create trigger insert_app_token_permission_subtype before insert on app_token_permission_project + for each row execute procedure insert_app_token_permission_subtype(); + +commit; diff --git a/internal/db/sqltest/Makefile b/internal/db/sqltest/Makefile index b85c76b996..2606f0505f 100644 --- a/internal/db/sqltest/Makefile +++ b/internal/db/sqltest/Makefile @@ -19,6 +19,7 @@ PROVE_OPTS ?= TESTS ?= tests/setup/*.sql \ tests/account/*/*.sql \ tests/alias/*.sql \ + tests/apptoken/*.sql \ tests/auth/*/*.sql \ tests/census/*.sql \ tests/controller/*.sql \ diff --git a/internal/db/sqltest/tests/apptoken/apptoken_global.sql b/internal/db/sqltest/tests/apptoken/apptoken_global.sql new file mode 100644 index 0000000000..60986242f1 --- /dev/null +++ b/internal/db/sqltest/tests/apptoken/apptoken_global.sql @@ -0,0 +1,226 @@ +-- Copyright (c) HashiCorp, Inc. +-- SPDX-License-Identifier: BUSL-1.1 + +begin; + +select plan(28); +select wtt_load('widgets', 'iam'); + +-- insert app_token_global and make sure app_token has a value +prepare insert_app_token_global as + insert into app_token_global ( + public_id, + scope_id, + revoked, + created_by_user_id, + create_time, + update_time, + approximate_last_access_time, + expiration_time + ) values ('r_1111111111', 'global', true, 'u_____walter', now(), now(), now(), now() + interval '7 day'); +select lives_ok('insert_app_token_global'); +-- ensure app_token has a value +select is(count(*), 1::bigint) from app_token where public_id = 'r_1111111111'; + +-- try to unrevoke a revoked app token global, should fail +prepare unrevoke_app_token_global as + update app_token_global + set revoked = false + where public_id = 'r_1111111111'; +select throws_like('unrevoke_app_token_global', 'App token cannot be unrevoked. revoked value. Current: t, Attempted: f'); + +-- update the approximate_last_access_time +prepare update_approximate_last_access_time as + update app_token_global + set approximate_last_access_time = now() + interval '2 days' + where public_id = 'r_1111111111'; +select lives_ok('update_approximate_last_access_time'); +-- ensure approximate_last_access_time was updated +select is(count(*), 1::bigint) from app_token_global + where public_id = 'r_1111111111' + and approximate_last_access_time > now() + interval '1 day'; +-- ensure approximate_last_access_time was updated in app_token table as well +select is(count(*), 1::bigint) from app_token + where public_id = 'r_1111111111' + and approximate_last_access_time > now() + interval '1 day'; + +-- insert into app_token_cipher table for the app token +prepare insert_app_token_cipher as + insert into app_token_cipher ( + app_token_id, + key_id, + token + ) values ('r_1111111111', 'kdkv__colors', 'ciphertext_example'); +select lives_ok('insert_app_token_cipher'); +-- ensure app_token_cipher has a value +select is(count(*), 1::bigint) from app_token_cipher where app_token_id = 'r_1111111111'; + +-- insert into app_token_cipher with non-existent app_token_id, should fail +prepare insert_app_token_cipher_invalid_token as + insert into app_token_cipher ( + app_token_id, + key_id, + token + ) values ('r_does_not_exist', 'kdkv__colors', 'ciphertext_two'); +select throws_like('insert_app_token_cipher_invalid_token', + 'insert or update on table "app_token_cipher" violates foreign key constraint "app_token_cipher_app_token_fkey"'); + +-- insert into app_token_cipher with duplicate app_token_id, should fail +prepare insert_duplicate_app_token_cipher as + insert into app_token_cipher ( + app_token_id, + key_id, + token + ) values ('r_1111111111', 'kdkv__colors', 'ciphertext_three'); +select throws_like('insert_duplicate_app_token_cipher', + 'duplicate key value violates unique constraint "app_token_cipher_pkey"'); + +-- insert app_token_cipher with duplicate token but different app_token_id, should fail +prepare insert_app_token_cipher_duplicate_token as + insert into app_token_cipher ( + app_token_id, + key_id, + token + ) values ('r_2222222222', 'kdkv__colors', 'ciphertext_example'); +select throws_like('insert_app_token_cipher_duplicate_token', + 'duplicate key value violates unique constraint "app_token_cipher_token_key"'); + +-- try to insert app_token_global with user that doesn't exist, should fail +prepare insert_app_token_global_invalid_user as + insert into app_token_global ( + public_id, + scope_id, + created_by_user_id + ) values ('r_2222222222', 'global', 'u_nonexistent_user'); +select throws_like('insert_app_token_global_invalid_user', 'User ID u_nonexistent_user does not exist in iam_user'); + +-- insert app_token_permission_global +prepare insert_app_token_permission_global as + insert into app_token_permission_global ( + private_id, + app_token_id, + grant_scope, + create_time + ) values ('p_1111111111', 'r_1111111111', 'individual', now()); +select lives_ok('insert_app_token_permission_global'); +-- ensure app_token_permission has a value +select is(count(*), 1::bigint) from app_token_permission where private_id = 'p_1111111111'; + +-- insert app_token_permission_global with duplicate grant_scope and private_id, should fail +prepare insert_duplicate_app_token_permission_global as + insert into app_token_permission_global ( + private_id, + app_token_id, + grant_scope, + create_time + ) values ('p_1111111111', 'r_1111111111', 'individual', now()); +select throws_like('insert_duplicate_app_token_permission_global', 'duplicate key value violates unique constraint "app_token_permission_pkey"'); + +-- insert app_token_permission_global_individual_org_grant_scope with: +-- individual grant_scope, permission_id that exists in app_token_permission_global, valid org scope id +prepare insert_app_token_permission_global_individual_org_grant_scope as + insert into app_token_permission_global_individual_org_grant_scope ( + permission_id, + scope_id, + grant_scope + ) values ('p_1111111111', 'o_____widget', 'individual'); +select lives_ok('insert_app_token_permission_global_individual_org_grant_scope'); + +-- insert app_token_permission_global_individual_org_grant_scope with: +-- individual grant_scope, permission_id that does not exist in app_token_permission_global, valid org scope id +-- should fail +prepare insert_app_token_pgi_org_grant_scope_invalid_permission_id as + insert into app_token_permission_global_individual_org_grant_scope ( + permission_id, + scope_id, + grant_scope + ) values ('p_nonexistent_permission', 'o_____widget', 'individual'); +select throws_like('insert_app_token_pgi_org_grant_scope_invalid_permission_id', + 'insert or update on table "app_token_permission_global_individual_org_grant_scope" violates foreign key constraint "app_token_permission_global_fkey"'); + +-- insert app_token_permission_global_individual_org_grant_scope with: +-- non-individual grant_scope, permission_id that exists in app_token_permission_global, valid org scope id +-- should fail +prepare insert_app_token_pgi_org_grant_scope_invalid_grant_scope as + insert into app_token_permission_global_individual_org_grant_scope ( + permission_id, + scope_id, + grant_scope + ) values ('p_1111111111', 'o_____widget', 'children'); +select throws_like('insert_app_token_pgi_org_grant_scope_invalid_grant_scope', + 'new row for relation "app_token_permission_global_individual_org_grant_scope" violates check constraint "only_individual_grant_scope_allowed"'); + +-- insert app_token_permission_global_individual_org_grant_scope with: +-- individual grant_scope, permission_id that exists in app_token_permission_global, invalid org scope id +-- should fail +prepare insert_app_token_pgi_org_grant_scope_invalid_scope_id as + insert into app_token_permission_global_individual_org_grant_scope ( + permission_id, + scope_id, + grant_scope + ) values ('p_1111111111', 'p_nonexistent_scope', 'individual'); +select throws_like('insert_app_token_pgi_org_grant_scope_invalid_scope_id', + 'org scope_id p_nonexistent_scope not found'); + +-- insert app_token_permission_global_individual_project_grant_scope with: +-- individual grant_scope, permission_id that exists in app_token_permission_global, valid project scope id +prepare insert_app_token_pgi_project_grant_scope as + insert into app_token_permission_global_individual_project_grant_scope ( + permission_id, + scope_id, + grant_scope + ) values ('p_1111111111', 'p____bwidget', 'individual'); +select lives_ok('insert_app_token_pgi_project_grant_scope'); + +-- insert app_token_permission_global_individual_project_grant_scope with: +-- individual grant_scope, permission_id that does not exist in app_token_permission_global, valid project scope id +-- should fail +prepare insert_app_token_pgi_project_grant_scope_invalid_permission_id as + insert into app_token_permission_global_individual_project_grant_scope ( + permission_id, + scope_id, + grant_scope + ) values ('p_nonexistent_permission', 'p____bwidget', 'individual'); +select throws_like('insert_app_token_pgi_project_grant_scope_invalid_permission_id', + 'insert or update on table "app_token_permission_global_individual_project_grant_scope" violates foreign key constraint "app_token_permission_global_fkey"'); + +-- insert duplicate app_token_permission_global_individual_project_grant_scope with: +-- different grant_scope, permission_id that exists in app_token_permission_global, valid project scope id +-- should fail +prepare insert_duplicate_app_token_pgi_project_grant_scope as + insert into app_token_permission_global_individual_project_grant_scope ( + permission_id, + scope_id, + grant_scope + ) values ('p_1111111111', 'p____bwidget', 'children'); +select throws_like('insert_duplicate_app_token_pgi_project_grant_scope', + 'duplicate key value violates unique constraint "app_token_permission_global_individual_project_grant_scope_pkey"'); + +-- insert app_token_permission_global_individual_project_grant_scope with: +-- individual grant_scope, permission_id that exists in app_token_permission_global, invalid project scope id +-- should fail +prepare insert_app_token_pgi_project_grant_scope_invalid_scope_id as + insert into app_token_permission_global_individual_project_grant_scope ( + permission_id, + scope_id, + grant_scope + ) values ('p_1111111111', 'p_nonexistent_scope', 'individual'); +select throws_like('insert_app_token_pgi_project_grant_scope_invalid_scope_id', + 'project scope_id p_nonexistent_scope not found'); + +-- delete token from app_token and ensure cascading delete to app_token_global and app_token_permission_global +prepare delete_app_token as + delete from app_token + where public_id = 'r_1111111111'; +select lives_ok('delete_app_token'); +-- ensure app_token is deleted +select is(count(*), 0::bigint) from app_token where public_id = 'r_1111111111'; +-- ensure token is automatically entered in app_token_deleted +select is(count(*), 1::bigint) from app_token_deleted where public_id = 'r_1111111111'; +-- ensure app_token_global is deleted +select is(count(*), 0::bigint) from app_token_global where public_id = 'r_1111111111'; +-- ensure app_token_permission_global is deleted +select is(count(*), 0::bigint) from app_token_permission_global where app_token_id = 'r_1111111111'; + +select * from finish(); +rollback; \ No newline at end of file diff --git a/internal/db/sqltest/tests/apptoken/apptoken_org.sql b/internal/db/sqltest/tests/apptoken/apptoken_org.sql new file mode 100644 index 0000000000..534c326693 --- /dev/null +++ b/internal/db/sqltest/tests/apptoken/apptoken_org.sql @@ -0,0 +1,124 @@ +-- Copyright (c) HashiCorp, Inc. +-- SPDX-License-Identifier: BUSL-1.1 + +begin; + +select plan(16); +select wtt_load('widgets', 'iam'); + +-- insert app_token_org and make sure app_token has a value +prepare insert_app_token_org as + insert into app_token_org ( + public_id, + scope_id, + revoked, + created_by_user_id, + create_time, + update_time, + approximate_last_access_time, + expiration_time + ) values ('r_1111111111', 'o_____widget', true, 'u_____walter', now(), now(), now(), now() + interval '1 day'); +select lives_ok('insert_app_token_org'); +-- ensure app_token has a value +select is(count(*), 1::bigint) from app_token where public_id = 'r_1111111111'; + +-- try to unrevoke a revoked app token org, should fail +prepare unrevoke_app_token_org as + update app_token_org + set revoked = false + where public_id = 'r_1111111111'; +select throws_like('unrevoke_app_token_org', 'App token cannot be unrevoked. revoked value. Current: t, Attempted: f'); + +-- try to insert app_token_org with user that doesn't exist, should fail +prepare insert_app_token_org_invalid_user as + insert into app_token_org ( + public_id, + scope_id, + created_by_user_id + ) values ('r_2222222222', 'o_____widget', 'u_nonexistent_user'); +select throws_like('insert_app_token_org_invalid_user', 'User ID u_nonexistent_user does not exist in iam_user'); + +-- insert app_token_permission_org +prepare insert_app_token_permission_org as + insert into app_token_permission_org ( + private_id, + app_token_id, + grant_scope, + create_time + ) values ('p_1111111111', 'r_1111111111', 'individual', now()); +select lives_ok('insert_app_token_permission_org'); +-- ensure app_token_permission has a value +select is(count(*), 1::bigint) from app_token_permission where private_id = 'p_1111111111'; + +-- insert app_token_permission_org with duplicate grant_scope and private_id, should fail +prepare insert_duplicate_app_token_permission_org as + insert into app_token_permission_org ( + private_id, + app_token_id, + grant_scope, + create_time + ) values ('p_1111111111', 'r_1111111111', 'individual', now()); +select throws_like('insert_duplicate_app_token_permission_org', 'duplicate key value violates unique constraint "app_token_permission_pkey"'); + +-- insert app_token_permission_org_individual_grant_scope with: +-- individual grant_scope, permission_id that exists in app_token_permission_org, valid org scope id +prepare insert_app_token_permission_org_individual_grant_scope as + insert into app_token_permission_org_individual_grant_scope ( + permission_id, + scope_id, + grant_scope + ) values ('p_1111111111', 'p____bwidget', 'individual'); +select lives_ok('insert_app_token_permission_org_individual_grant_scope'); + +-- insert app_token_permission_org_individual_grant_scope with: +-- individual grant_scope, permission_id that does not exist in app_token_permission_org, valid org scope id +-- should fail +prepare insert_app_token_poi_grant_scope_invalid_permission_id as + insert into app_token_permission_org_individual_grant_scope ( + permission_id, + scope_id, + grant_scope + ) values ('p_nonexistent_permission', 'p____bwidget', 'individual'); +select throws_like('insert_app_token_poi_grant_scope_invalid_permission_id', + 'permission_id p_nonexistent_permission not found or has no associated app token'); + +-- insert app_token_permission_org_individual_grant_scope with: +-- non-individual grant_scope, permission_id that exists in app_token_permission_org, valid org scope id +-- should fail +prepare insert_app_token_poi_grant_scope_invalid_grant_scope as + insert into app_token_permission_org_individual_grant_scope ( + permission_id, + scope_id, + grant_scope + ) values ('p_1111111111', 'p____bwidget', 'children'); +select throws_like('insert_app_token_poi_grant_scope_invalid_grant_scope', + 'new row for relation "app_token_permission_org_individual_grant_scope" violates check constraint "only_individual_grant_scope_allowed"'); + +-- insert app_token_permission_org_individual_grant_scope with: +-- individual grant_scope, permission_id that exists in app_token_permission_org, invalid org scope id +-- should fail +prepare insert_app_token_pgi_org_grant_scope_invalid_scope_id as + insert into app_token_permission_org_individual_grant_scope ( + permission_id, + scope_id, + grant_scope + ) values ('p_1111111111', 'p_nonexistent_scope', 'individual'); +select throws_like('insert_app_token_pgi_org_grant_scope_invalid_scope_id', + 'project scope_id p_nonexistent_scope not found or is not a child of org o_____widget'); + +-- delete token from app_token and ensure cascading delete to app_token_org and app_token_permission_org +prepare delete_app_token as + delete from app_token + where public_id = 'r_1111111111'; +select lives_ok('delete_app_token'); +-- ensure app_token is deleted +select is(count(*), 0::bigint) from app_token where public_id = 'r_1111111111'; +-- ensure token is automatically entered in app_token_deleted +select is(count(*), 1::bigint) from app_token_deleted where public_id = 'r_1111111111'; +-- ensure app_token_org is deleted +select is(count(*), 0::bigint) from app_token_org where public_id = 'r_1111111111'; +-- ensure app_token_permission_org is deleted +select is(count(*), 0::bigint) from app_token_permission_org where app_token_id = 'r_1111111111'; + +select * from finish(); +rollback; \ No newline at end of file diff --git a/internal/db/sqltest/tests/apptoken/apptoken_project.sql b/internal/db/sqltest/tests/apptoken/apptoken_project.sql new file mode 100644 index 0000000000..0d82125ba0 --- /dev/null +++ b/internal/db/sqltest/tests/apptoken/apptoken_project.sql @@ -0,0 +1,93 @@ +-- Copyright (c) HashiCorp, Inc. +-- SPDX-License-Identifier: BUSL-1.1 + +begin; + +select plan(15); +select wtt_load('widgets', 'iam'); + +-- insert app_token_project and make sure app_token has a value +prepare insert_app_token_project as + insert into app_token_project ( + public_id, + scope_id, + revoked, + created_by_user_id, + create_time, + update_time, + approximate_last_access_time, + expiration_time + ) values ('r_1111111111', 'p____bwidget', true, 'u_____walter', now(), now(), now(), now() + interval '7 day'); +select lives_ok('insert_app_token_project'); +-- ensure app_token has a value +select is(count(*), 1::bigint) from app_token where public_id = 'r_1111111111'; + +-- try to unrevoke a revoked app token global, should fail +prepare unrevoke_app_token_project as + update app_token_project + set revoked = false + where public_id = 'r_1111111111'; +select throws_like('unrevoke_app_token_project', 'App token cannot be unrevoked. revoked value. Current: t, Attempted: f'); + +-- update the approximate_last_access_time +prepare update_approximate_last_access_time as + update app_token_project + set approximate_last_access_time = now() + interval '2 days' + where public_id = 'r_1111111111'; +select lives_ok('update_approximate_last_access_time'); +-- ensure approximate_last_access_time was updated +select is(count(*), 1::bigint) from app_token_project + where public_id = 'r_1111111111' + and approximate_last_access_time > now() + interval '1 day'; +-- ensure approximate_last_access_time was updated in app_token table as well +select is(count(*), 1::bigint) from app_token + where public_id = 'r_1111111111' + and approximate_last_access_time > now() + interval '1 day'; + +-- try to insert app_token_project with user that doesn't exist, should fail +prepare insert_app_token_project_invalid_user as + insert into app_token_project ( + public_id, + scope_id, + created_by_user_id + ) values ('r_2222222222', 'global', 'u_nonexistent_user'); +select throws_like('insert_app_token_project_invalid_user', 'User ID u_nonexistent_user does not exist in iam_user'); + +-- insert app_token_permission_project +prepare insert_app_token_permission_project as + insert into app_token_permission_project ( + private_id, + app_token_id, + grant_this_scope, + create_time + ) values ('p_1111111111', 'r_1111111111', 'true', now()); +select lives_ok('insert_app_token_permission_project'); +-- ensure app_token_permission has a value +select is(count(*), 1::bigint) from app_token_permission where private_id = 'p_1111111111'; + +-- insert app_token_permission_project with duplicate grant_scope and private_id, should fail +prepare insert_duplicate_app_token_permission_project as + insert into app_token_permission_project ( + private_id, + app_token_id, + grant_this_scope, + create_time + ) values ('p_1111111111', 'r_1111111111', true, now()); +select throws_like('insert_duplicate_app_token_permission_project', 'duplicate key value violates unique constraint "app_token_permission_pkey"'); + +-- delete token from app_token and ensure cascading delete to app_token_project and app_token_permission_project +prepare delete_app_token as + delete from app_token + where public_id = 'r_1111111111'; +select lives_ok('delete_app_token'); +-- ensure app_token is deleted +select is(count(*), 0::bigint) from app_token where public_id = 'r_1111111111'; +-- ensure token is automatically entered in app_token_deleted +select is(count(*), 1::bigint) from app_token_deleted where public_id = 'r_1111111111'; +-- ensure app_token_project is deleted +select is(count(*), 0::bigint) from app_token_project where public_id = 'r_1111111111'; +-- ensure app_token_permission_project is deleted +select is(count(*), 0::bigint) from app_token_permission_project where app_token_id = 'r_1111111111'; + +select * from finish(); +rollback; \ No newline at end of file