Skip to content

Commit

Permalink
feat: Setup flow_status_history table
Browse files Browse the repository at this point in the history
- Setup table and populate
- Setup trigger
- Add status column to flows, setup permissions
  • Loading branch information
DafyddLlyr committed May 20, 2024
1 parent e14b166 commit e5a03c2
Show file tree
Hide file tree
Showing 3 changed files with 103 additions and 33 deletions.
51 changes: 18 additions & 33 deletions hasura.planx.uk/metadata/tables.yaml
Original file line number Diff line number Diff line change
Expand Up @@ -362,6 +362,13 @@
- document_template
- flow_id
filter: {}
- table:
name: flow_status_enum
schema: public
is_enum: true
- table:
name: flow_status_history
schema: public
- table:
name: flows
schema: public
Expand Down Expand Up @@ -527,7 +534,9 @@
- version
computed_fields:
- data_merged
filter: {}
filter:
status:
_eq: online
allow_aggregations: true
- role: teamEditor
permission:
Expand All @@ -550,16 +559,17 @@
- role: api
permission:
columns:
- copied_from
- created_at
- creator_id
- team_id
- data
- id
- settings
- slug
- created_at
- status
- team_id
- updated_at
- copied_from
- id
- version
- data
filter: {}
check: {}
validate_input:
Expand All @@ -577,6 +587,7 @@
- data
- settings
- slug
- status
- team_id
filter: {}
check: null
Expand All @@ -595,6 +606,7 @@
- data
- settings
- slug
- status
- team_id
filter:
team:
Expand Down Expand Up @@ -1434,33 +1446,6 @@
- table:
name: submission_services_log
schema: public
select_permissions:
- role: platformAdmin
permission:
columns:
- retry
- response
- event_id
- event_type
- status
- created_at
- flow_id
- session_id
filter: {}
comment: ""
- role: teamEditor
permission:
columns:
- retry
- response
- event_id
- event_type
- status
- created_at
- flow_id
- session_id
filter: {}
comment: ""
- table:
name: submission_services_summary
schema: public
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,11 @@
DROP TRIGGER IF EXISTS flow_status_history_trigger on flows;
DROP FUNCTION IF EXISTS track_flow_status_history();

DROP TABLE "public"."flow_status_history";

alter table
"public"."flows" drop constraint "flows_status_fkey";

ALTER TABLE flows DROP COLUMN "status";

DROP TABLE "public"."flow_status_enum";
Original file line number Diff line number Diff line change
@@ -0,0 +1,74 @@
-- Setup enum table of possible values for flow.status
CREATE TABLE "public"."flow_status_enum" (
"value" text NOT NULL,
"comment" text,
PRIMARY KEY ("value")
);

COMMENT ON TABLE "public"."flow_status_enum" IS E'An enum for tracking the status of a flow';

INSERT INTO "public"."flow_status_enum"("value", "comment") VALUES (E'online', null);
INSERT INTO "public"."flow_status_enum"("value", "comment") VALUES (E'offline', null);

-- Add flow.status column
alter table "public"."flows" add column "status" text
not null default 'online';

alter table "public"."flows"
add constraint "flows_status_fkey"
foreign key ("status")
references "public"."flow_status_enum"
("value") on update restrict on delete restrict;

-- Create audit table to track changes to status
-- Could be used for analytics or other audit features in future
CREATE TABLE "public"."flow_status_history" (
"id" serial NOT NULL,
"flow_id" uuid NOT NULL,
"status" text NOT NULL,
"event_start" timestamptz NOT NULL,
"event_end" timestamptz,
PRIMARY KEY ("id"),
FOREIGN KEY ("flow_id") REFERENCES "public"."flows"("id") ON UPDATE restrict ON DELETE cascade,
FOREIGN KEY ("status") REFERENCES "public"."flow_status_enum"("value") ON UPDATE restrict ON DELETE restrict,
UNIQUE ("id")
);

COMMENT ON TABLE "public"."flow_status_history" IS E'Temporal table to track the status of a flow over time';

-- Populate initial table values
-- All flows have had status "online" since they were created
INSERT INTO flow_status_history (flow_id, status, event_start)
SELECT id, 'online', created_at
FROM flows;

-- Setup function which updates and adds audit records to flow_status_history
CREATE OR REPLACE FUNCTION track_flow_status_history()
RETURNS TRIGGER AS $$
BEGIN
IF (TG_OP = 'UPDATE') THEN
-- End previous event
UPDATE flow_status_history
SET event_end = NOW()
WHERE flow_id = OLD.id AND event_end IS NULL;

-- Start new event
INSERT INTO flow_status_history (flow_id, status, event_start)
VALUES (NEW.id, OLD.status, NOW());

ELSIF (TG_OP = 'INSERT') THEN
-- Start new event
INSERT INTO flow_status_history (flow_id, status, event_start)
VALUES (NEW.id, NEW.status, NOW());
END IF;
RETURN NEW;
END;
$$ LANGUAGE plpgsql;

-- Trigger to call above function
-- Called on insert or update to flows.status
CREATE TRIGGER flow_status_history_trigger
AFTER INSERT OR UPDATE OF status ON flows
FOR EACH ROW
EXECUTE FUNCTION track_flow_status_history();

0 comments on commit e5a03c2

Please sign in to comment.