From b2349a5d1640a8df323e7c5e752ccb193b7965e0 Mon Sep 17 00:00:00 2001 From: Britney Epps Date: Tue, 8 Mar 2022 12:37:04 -0500 Subject: [PATCH] Created an audit table to track application history (#647) * create audit table for applications and create audit trigger for table insert * Added application-status audit table and fuctions Co-authored-by: britneyepps --- .../V35__create-applications-audit-table.sql | 20 +++++++++++++++++ ...6__add-triggers-for-applications-audit.sql | 22 +++++++++++++++++++ .../V37__create-applications-status-table.sql | 12 ++++++++++ ...riggers-for-application-statuses-audit.sql | 22 +++++++++++++++++++ 4 files changed, 76 insertions(+) create mode 100644 src/main/resources/db/migration/V35__create-applications-audit-table.sql create mode 100644 src/main/resources/db/migration/V36__add-triggers-for-applications-audit.sql create mode 100644 src/main/resources/db/migration/V37__create-applications-status-table.sql create mode 100644 src/main/resources/db/migration/V38__add-triggers-for-application-statuses-audit.sql diff --git a/src/main/resources/db/migration/V35__create-applications-audit-table.sql b/src/main/resources/db/migration/V35__create-applications-audit-table.sql new file mode 100644 index 000000000..98c286a57 --- /dev/null +++ b/src/main/resources/db/migration/V35__create-applications-audit-table.sql @@ -0,0 +1,20 @@ +CREATE TABLE applications_audit +( + op CHAR(1) NOT NULL, + op_at TIMESTAMP WITHOUT TIME ZONE NOT NULL, + op_by VARCHAR NOT NULL, + application_id VARCHAR NOT NULL, + completed_at TIMESTAMP WITHOUT TIME ZONE, + county VARCHAR NOT NULL DEFAULT 'OTHER', + time_to_complete INTEGER DEFAULT 0, + sentiment VARCHAR, + feedback TEXT, + flow VARCHAR, + application_data jsonb, + updated_at timestamp, + caf_application_status VARCHAR, + ccap_application_status VARCHAR, + uploaded_documents_status VARCHAR, + doc_upload_email_status VARCHAR, + certain_pops_application_status VARCHAR +) \ No newline at end of file diff --git a/src/main/resources/db/migration/V36__add-triggers-for-applications-audit.sql b/src/main/resources/db/migration/V36__add-triggers-for-applications-audit.sql new file mode 100644 index 000000000..ba9c0299c --- /dev/null +++ b/src/main/resources/db/migration/V36__add-triggers-for-applications-audit.sql @@ -0,0 +1,22 @@ +create or replace function fn_applications_audit() returns trigger +as +$applications_audit$ + +begin + if (TG_OP = 'DELETE') THEN + insert into applications_audit SELECT 'D', now(), user, OLD.*; + elsif (TG_OP = 'UPDATE') THEN + insert into applications_audit SELECT 'U', now(), user, NEW.*; + elsif (TG_OP = 'INSERT') THEN + insert into applications_audit SELECT 'I', now(), user, NEW.*; + end if; + return null; +end; + +$applications_audit$ + language plpgsql; + +create trigger tr_applications_audit_trigger + after insert or update or delete on applications + for each row +execute procedure fn_applications_audit(); \ No newline at end of file diff --git a/src/main/resources/db/migration/V37__create-applications-status-table.sql b/src/main/resources/db/migration/V37__create-applications-status-table.sql new file mode 100644 index 000000000..c9b002d0a --- /dev/null +++ b/src/main/resources/db/migration/V37__create-applications-status-table.sql @@ -0,0 +1,12 @@ +CREATE TABLE application_statuses_audit +( + op CHAR(1) NOT NULL, + op_at TIMESTAMP WITHOUT TIME ZONE NOT NULL, + op_by VARCHAR NOT NULL, + application_id VARCHAR NOT NULL, + document_type VARCHAR NOT NULL, + routing_destination VARCHAR NOT NULL, + status VARCHAR NOT NULL, + created_at TIMESTAMP WITHOUT TIME ZONE DEFAULT NOW(), + updated_at TIMESTAMP WITHOUT TIME ZONE DEFAULT NOW() +) \ No newline at end of file diff --git a/src/main/resources/db/migration/V38__add-triggers-for-application-statuses-audit.sql b/src/main/resources/db/migration/V38__add-triggers-for-application-statuses-audit.sql new file mode 100644 index 000000000..0f6a28b82 --- /dev/null +++ b/src/main/resources/db/migration/V38__add-triggers-for-application-statuses-audit.sql @@ -0,0 +1,22 @@ +create or replace function fn_application_statuses_audit() returns trigger +as +$application_statuses_audit$ + +begin + if (TG_OP = 'DELETE') THEN + insert into application_statuses_audit SELECT 'D', now(), user, OLD.*; + elsif (TG_OP = 'UPDATE') THEN + insert into application_statuses_audit SELECT 'U', now(), user, NEW.*; + elsif (TG_OP = 'INSERT') THEN + insert into application_statuses_audit SELECT 'I', now(), user, NEW.*; + end if; + return null; +end; + +$application_statuses_audit$ + language plpgsql; + +create trigger tr_application_statuses_audit_trigger + after insert or update or delete on application_status + for each row +execute procedure fn_application_statuses_audit(); \ No newline at end of file