diff --git a/server/flyway/sql/V55__create_permission_audit_and_code_tables.sql b/server/flyway/sql/V55__create_permission_audit_and_code_tables.sql new file mode 100644 index 000000000..f7beb2cbd --- /dev/null +++ b/server/flyway/sql/V55__create_permission_audit_and_code_tables.sql @@ -0,0 +1,113 @@ +-- Create a permission audit table and a code table https://github.com/bcgov/nr-forests-access-management/issues/1536 + +/*============================================================= += fam_privilege_change_type = +=============================================================*/ + +-- Create the fam_privilege_change_type table +CREATE TABLE app_fam.fam_privilege_change_type ( + privilege_change_type_code VARCHAR(10) PRIMARY KEY, + description VARCHAR(100) NOT NULL, + effective_date TIMESTAMP(6) WITHOUT TIME ZONE DEFAULT NOW() NOT NULL, + expiry_date TIMESTAMP(6) WITHOUT TIME ZONE, + update_date TIMESTAMP(6) WITHOUT TIME ZONE +); + +-- Permission for fam_privilege_change_type +GRANT +SELECT + ON app_fam.fam_privilege_change_type TO ${admin_management_api_db_user}, ${api_db_username}; + +-- Insert the values into the fam_privilege_change_type table +INSERT INTO + app_fam.fam_privilege_change_type ( + privilege_change_type_code, + description, + effective_date + ) +VALUES + ( + 'GRANT', + 'Grant', + '2024-09-03' + ), + ( + 'REVOKE', + 'Revoke', + '2024-09-03' + ), + ( + 'UPDATE', + 'Update access', + '2024-09-03' + ); + +-- Add comments to the fam_privilege_change_type table and its columns +COMMENT ON TABLE app_fam.fam_privilege_change_type IS 'Table containing types of privilege changes such as Grant, Revoke, or Update access.'; + +COMMENT ON COLUMN app_fam.fam_privilege_change_type.privilege_change_type_code IS 'Primary key that identifies the type of privilege change (Grant, Revoke, or Update access).'; + +COMMENT ON COLUMN app_fam.fam_privilege_change_type.description IS 'Description of the privilege change type.'; + +COMMENT ON COLUMN app_fam.fam_privilege_change_type.effective_date IS 'Date when the privilege change becomes effective.'; + +COMMENT ON COLUMN app_fam.fam_privilege_change_type.expiry_date IS 'Date when the privilege change expires or is no longer valid.'; + +COMMENT ON COLUMN app_fam.fam_privilege_change_type.update_date IS 'Date when the record was last updated.'; + + +/*============================================================= += fam_privilege_change_audit = +=============================================================*/ + +-- Create the fam_privilege_change_audit table +CREATE TABLE IF NOT EXISTS app_fam.fam_privilege_change_audit ( + privilege_change_audit_id BIGINT GENERATED BY DEFAULT AS IDENTITY (START WITH 1 INCREMENT BY 1) PRIMARY KEY, + application_id BIGINT NOT NULL, + change_date TIMESTAMP(6) WITH TIME ZONE NOT NULL, + change_performer_user_details JSONB NOT NULL, + change_performer_user_id BIGINT, + change_target_user_id BIGINT NOT NULL, + create_date TIMESTAMP(6) WITH TIME ZONE NOT NULL, + create_user VARCHAR(100) NOT NULL, + privilege_change_type_code VARCHAR(10) NOT NULL, + privilege_details JSONB NOT NULL, + CONSTRAINT fk_application FOREIGN KEY (application_id) REFERENCES app_fam.fam_application(application_id), + CONSTRAINT fk_change_performer_user FOREIGN KEY (change_performer_user_id) REFERENCES app_fam.fam_user(user_id), + CONSTRAINT fk_change_target_user FOREIGN KEY (change_target_user_id) REFERENCES app_fam.fam_user(user_id), + CONSTRAINT fk_privilege_change_type FOREIGN KEY (privilege_change_type_code) REFERENCES app_fam.fam_privilege_change_type(privilege_change_type_code) +); + +-- Create index on application_id +CREATE INDEX idx_fam_privilege_change_audit_application_id ON app_fam.fam_privilege_change_audit(application_id); + +-- Create index on change_target_user_id +CREATE INDEX idx_fam_privilege_change_audit_change_target_user_id ON app_fam.fam_privilege_change_audit(change_target_user_id); + +-- Permission for fam_privilege_change_audit +GRANT +SELECT, INSERT + ON app_fam.fam_privilege_change_audit TO ${admin_management_api_db_user}, ${api_db_username}; + +-- Comments on fam_privilege_change_audit +COMMENT ON TABLE app_fam.fam_privilege_change_audit IS 'Audit log tracking privilege changes, including details of the change, performer, and target user.'; + +COMMENT ON COLUMN app_fam.fam_privilege_change_audit.privilege_change_audit_id IS 'Identity column acting as surrogate primary key'; + +COMMENT ON COLUMN app_fam.fam_privilege_change_audit.application_id IS 'Foreign key to fam_application. Specifies the application for which the privilege change was made.'; + +COMMENT ON COLUMN app_fam.fam_privilege_change_audit.change_date IS 'Date & time of the privilege change. For initial data migration, this is NOT the same as the create time of this audit record.'; + +COMMENT ON COLUMN app_fam.fam_privilege_change_audit.change_performer_user_details IS 'JSON-formatted document describing the user that performed the change.'; + +COMMENT ON COLUMN app_fam.fam_privilege_change_audit.change_performer_user_id IS 'Specifies the user that initiated the privilege change. Foreign key to fam_user. Nullable when access was granted by a system change.'; + +COMMENT ON COLUMN app_fam.fam_privilege_change_audit.change_target_user_id IS 'Specifies the user that the privilege change was performed on. Foreign key to fam_user.'; + +COMMENT ON COLUMN app_fam.fam_privilege_change_audit.create_date IS 'The date and time the record was created. Not necessarily the same time as when the privilege change occurred.'; + +COMMENT ON COLUMN app_fam.fam_privilege_change_audit.create_user IS 'The user or system account that created the record. Not necessarily the same as the user that performed the privilege change.'; + +COMMENT ON COLUMN app_fam.fam_privilege_change_audit.privilege_change_type_code IS 'Foreign key to fam_privilege_change_type code table. Identifies the type of privilege change (Grant, Revoke, or Update access).'; + +COMMENT ON COLUMN app_fam.fam_privilege_change_audit.privilege_details IS 'JSON-formatted document describing the privilege(s) being changed. E.g. For end user permissions, this is details about the fam_role(s).';