Skip to content

Commit

Permalink
Created an audit table to track application history (#647)
Browse files Browse the repository at this point in the history
* create audit table for applications and create audit trigger for table insert

* Added application-status audit table and fuctions

Co-authored-by: britneyepps <bepps@codeforamerica.org>
  • Loading branch information
britneyepps and britneyepps committed Mar 8, 2022
1 parent ac44230 commit b2349a5
Show file tree
Hide file tree
Showing 4 changed files with 76 additions and 0 deletions.
Original file line number Diff line number Diff line change
@@ -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
)
Original file line number Diff line number Diff line change
@@ -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();
Original file line number Diff line number Diff line change
@@ -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()
)
Original file line number Diff line number Diff line change
@@ -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();

0 comments on commit b2349a5

Please sign in to comment.