Skip to content

Commit

Permalink
db script for events
Browse files Browse the repository at this point in the history
Signed-off-by: Gaurav Gahlot <gauravgahlot0107@gmail.com>
  • Loading branch information
gauravgahlot committed Sep 25, 2020
1 parent 3589d9a commit b42b2c7
Showing 1 changed file with 93 additions and 0 deletions.
93 changes: 93 additions & 0 deletions deploy/db/tinkerbell-init.sql
Original file line number Diff line number Diff line change
Expand Up @@ -74,3 +74,96 @@ CREATE TABLE IF NOT EXISTS workflow_data (
, metadata JSONB
, data JSONB
);

CREATE EXTENSION "uuid-ossp";
CREATE TYPE resource_type AS ENUM ('HARDWARE', 'TEMPLATE', 'WORKFLOW');
CREATE TYPE event_type AS ENUM ('CREATED', 'UPDATED', 'DELETED');

CREATE TABLE IF NOT EXISTS events (
id UUID UNIQUE DEFAULT uuid_generate_v4()
, resource_id UUID NOT NULL
, resource_type resource_type NOT NULL
, event_type event_type NOT NULL
, created_at TIMESTAMPTZ PRIMARY KEY DEFAULT now()
, data JSONB
);

CREATE INDEX IF NOT EXISTS idx_events_id ON events (id);
CREATE INDEX IF NOT EXISTS idx_events_event_type ON events (event_type);
CREATE INDEX IF NOT EXISTS idx_events_resource_id ON events (resource_id);
CREATE INDEX IF NOT EXISTS idx_events_resource_type ON events (resource_type);

CREATE OR REPLACE FUNCTION events_notify_changes()
RETURNS trigger AS $$
BEGIN
PERFORM pg_notify('events_channel', row_to_json(NEW)::text);
RETURN NULL;
END;
$$ LANGUAGE plpgsql;

CREATE TRIGGER events_channel
AFTER INSERT ON events
FOR EACH ROW EXECUTE PROCEDURE events_notify_changes();

CREATE OR REPLACE FUNCTION hardware_event()
RETURNS trigger AS $$
BEGIN
IF (TG_OP = 'INSERT') THEN
INSERT INTO events(resource_id, resource_type, event_type, data) VALUES (new.id, 'HARDWARE', 'CREATED', row_to_json(new));
ELSE
IF new.deleted_at IS NULL THEN
INSERT INTO events(resource_id, resource_type, event_type, data) VALUES (new.id, 'HARDWARE', 'UPDATED', row_to_json(new));
ELSE
INSERT INTO events(resource_id, resource_type, event_type, data) VALUES (new.id, 'HARDWARE', 'DELETED', row_to_json(new));
END IF;
END IF;

RETURN NULL;
END;
$$ LANGUAGE plpgsql;

CREATE TRIGGER hardware_trigger
AFTER INSERT OR UPDATE ON hardware
FOR EACH ROW EXECUTE PROCEDURE hardware_event();

CREATE OR REPLACE FUNCTION template_event()
RETURNS trigger AS $$
BEGIN
IF (TG_OP = 'INSERT') THEN
INSERT INTO events(resource_id, resource_type, event_type, data) VALUES (new.id, 'TEMPLATE', 'CREATED', row_to_json(new));
ELSE
IF new.deleted_at IS NULL THEN
INSERT INTO events(resource_id, resource_type, event_type, data) VALUES (new.id, 'TEMPLATE', 'UPDATED', row_to_json(new));
ELSE
INSERT INTO events(resource_id, resource_type, event_type, data) VALUES (new.id, 'TEMPLATE', 'DELETED', row_to_json(new));
END IF;
END IF;

RETURN NULL;
END;
$$ LANGUAGE plpgsql;

CREATE TRIGGER template_trigger
AFTER INSERT OR UPDATE ON template
FOR EACH ROW EXECUTE PROCEDURE template_event();

CREATE OR REPLACE FUNCTION workflow_event()
RETURNS trigger AS $$
BEGIN
IF (TG_OP = 'INSERT') THEN
INSERT INTO events(resource_id, resource_type, event_type, data) VALUES (new.id, 'WORKFLOW', 'CREATED', row_to_json(new));
ELSE
IF new.deleted_at IS NULL THEN
INSERT INTO events(resource_id, resource_type, event_type, data) VALUES (new.id, 'WORKFLOW', 'UPDATED', row_to_json(new));
ELSE
INSERT INTO events(resource_id, resource_type, event_type, data) VALUES (new.id, 'WORKFLOW', 'DELETED', row_to_json(new));
END IF;
END IF;

RETURN NULL;
END;
$$ LANGUAGE plpgsql;

CREATE TRIGGER workflow_trigger
AFTER INSERT OR UPDATE ON workflow
FOR EACH ROW EXECUTE PROCEDURE workflow_event();

0 comments on commit b42b2c7

Please sign in to comment.