Skip to content

Commit

Permalink
PostgreSQL Triggers for Incremental Config Changes
Browse files Browse the repository at this point in the history
On an INSERT or UPDATE on each row of a "main configuration tables", as
listed in the ConfigSet Go struct, the changed_at column field will
automatically be bumped to the current timestamp.

Furthermore, the "relationship tables" will update the changed_at field
in its referred row in the main table for INSERT, UPDATE or DELETE.
  • Loading branch information
oxzi committed May 3, 2024
1 parent 6fc5530 commit 433760f
Show file tree
Hide file tree
Showing 2 changed files with 261 additions and 15 deletions.
141 changes: 134 additions & 7 deletions schema/pgsql/schema.sql
Original file line number Diff line number Diff line change
Expand Up @@ -26,6 +26,68 @@ CREATE OR REPLACE FUNCTION anynonarrayliketext(anynonarray, text)
$$;
CREATE OPERATOR ~~ (LEFTARG=anynonarray, RIGHTARG=text, PROCEDURE=anynonarrayliketext);

-- incr_cfg_bump_changed_at is a BEFORE TRIGGER for INSERT/UPDATE, setting changed_at to the current timestamp.
CREATE FUNCTION incr_cfg_bump_changed_at()
RETURNS trigger
LANGUAGE plpgsql
AS $$
BEGIN
NEW.changed_at = EXTRACT(EPOCH FROM NOW()) * 1000;
RETURN NEW;
END;
$$;

-- incr_cfg_bump_changed_at_relation is an AFTER TRIGGER updating the changed_at column of another table. This function
-- might be used on relationship tables to bump the changed_at of their "main" table. It expects the foreign key table
-- name as its parameter. Due to our convention, the foreign key field will be "${foreign_table}_id", being accessed.
CREATE FUNCTION incr_cfg_bump_changed_at_relation() -- foreign_tbl text
RETURNS trigger
LANGUAGE plpgsql
AS $$
DECLARE
foreign_tbl TEXT := TG_ARGV[0];
update_id BIGINT;
BEGIN
IF (TG_OP = 'DELETE') THEN
update_id := row_to_json(OLD)->>format('%s_id', foreign_tbl);
ELSE
update_id := row_to_json(NEW)->>format('%s_id', foreign_tbl);
END IF;
EXECUTE format('
UPDATE %s
SET changed_at = EXTRACT(EPOCH FROM NOW()) * 1000
WHERE id = %s', foreign_tbl, update_id);
RETURN NULL;
END;
$$;

-- incr_cfg_bump_changed_at_relation_2nd is similar to incr_cfg_bump_changed_at_relation, just allowing one additional
-- relationship table in between, like: $tbl -> $join_tbl -> $foreign_tbl. Thus, it has two arguments: first the name of
-- the join table, which is referenced from the table having the trigger attached, and second the destination or foreign
-- table where changed_at should be bumped.
CREATE FUNCTION incr_cfg_bump_changed_at_relation_2nd() -- join_tbl text, foreign_tbl text
RETURNS trigger
LANGUAGE plpgsql
AS $$
DECLARE
join_tbl TEXT := TG_ARGV[0];
foreign_tbl TEXT := TG_ARGV[1];
join_update_id BIGINT;
BEGIN
IF (TG_OP = 'DELETE') THEN
join_update_id := row_to_json(OLD)->>format('%s_id', join_tbl);
ELSE
join_update_id := row_to_json(NEW)->>format('%s_id', join_tbl);
END IF;
EXECUTE format('
UPDATE %1$s
SET changed_at = EXTRACT(EPOCH FROM NOW()) * 1000
WHERE id IN (SELECT %1$s_id FROM %2$s WHERE id = %3s)',
foreign_tbl, join_tbl, join_update_id);
RETURN NULL;
END;
$$;

CREATE TABLE available_channel_type (
type text NOT NULL,
name text NOT NULL,
Expand All @@ -52,14 +114,19 @@ CREATE TABLE channel (

CREATE INDEX idx_channel_changed_at ON channel(changed_at);

CREATE TRIGGER trg_channel_incr_cfg_update
BEFORE INSERT OR UPDATE ON channel
FOR EACH ROW
EXECUTE FUNCTION incr_cfg_bump_changed_at();

CREATE TABLE contact (
id bigserial,
full_name text NOT NULL,
username text, -- reference to web user
default_channel_id bigint NOT NULL REFERENCES channel(id),
color varchar(7) NOT NULL, -- hex color codes e.g #000000

changed_at bigint NOT NULL DEFAULT extract(epoch from now()) * 1000,
changed_at bigint NOT NULL DEFAULT EXTRACT(EPOCH FROM NOW()) * 1000,
deleted boolenum NOT NULL DEFAULT 'n',

CONSTRAINT pk_contact PRIMARY KEY (id),
Expand All @@ -68,13 +135,18 @@ CREATE TABLE contact (

CREATE INDEX idx_contact_changed_at ON contact(changed_at);

CREATE TRIGGER trg_contact_incr_cfg_update
BEFORE INSERT OR UPDATE ON contact
FOR EACH ROW
EXECUTE FUNCTION incr_cfg_bump_changed_at();

CREATE TABLE contact_address (
id bigserial,
contact_id bigint NOT NULL REFERENCES contact(id),
type text NOT NULL, -- 'phone', 'email', ...
address text NOT NULL, -- phone number, email address, ...

changed_at bigint NOT NULL DEFAULT extract(epoch from now()) * 1000,
changed_at bigint NOT NULL DEFAULT EXTRACT(EPOCH FROM NOW()) * 1000,
deleted boolenum NOT NULL DEFAULT 'n',

CONSTRAINT pk_contact_address PRIMARY KEY (id),
Expand All @@ -83,19 +155,29 @@ CREATE TABLE contact_address (

CREATE INDEX idx_contact_address_changed_at ON contact_address(changed_at);

CREATE TRIGGER trg_contact_address_incr_cfg_update
BEFORE INSERT OR UPDATE ON contact_address
FOR EACH ROW
EXECUTE FUNCTION incr_cfg_bump_changed_at();

CREATE TABLE contactgroup (
id bigserial,
name text NOT NULL,
color varchar(7) NOT NULL, -- hex color codes e.g #000000

changed_at bigint NOT NULL DEFAULT extract(epoch from now()) * 1000,
changed_at bigint NOT NULL DEFAULT EXTRACT(EPOCH FROM NOW()) * 1000,
deleted boolenum NOT NULL DEFAULT 'n',

CONSTRAINT pk_contactgroup PRIMARY KEY (id)
);

CREATE INDEX idx_contactgroup_changed_at ON contactgroup(changed_at);

CREATE TRIGGER trg_contactgroup_incr_cfg_update
BEFORE INSERT OR UPDATE ON contactgroup
FOR EACH ROW
EXECUTE FUNCTION incr_cfg_bump_changed_at();

-- Changes to contactgroup_member should be notified by an updated contactgroup.changed_at.
CREATE TABLE contactgroup_member (
contactgroup_id bigint NOT NULL REFERENCES contactgroup(id),
Expand All @@ -104,30 +186,45 @@ CREATE TABLE contactgroup_member (
CONSTRAINT pk_contactgroup_member PRIMARY KEY (contactgroup_id, contact_id)
);

CREATE TRIGGER trg_contactgroup_member_changed_at_relation
AFTER INSERT OR UPDATE OR DELETE ON contactgroup_member
FOR EACH ROW
EXECUTE FUNCTION incr_cfg_bump_changed_at_relation('contactgroup');

CREATE TABLE schedule (
id bigserial,
name text NOT NULL,

changed_at bigint NOT NULL DEFAULT extract(epoch from now()) * 1000,
changed_at bigint NOT NULL DEFAULT EXTRACT(EPOCH FROM NOW()) * 1000,
deleted boolenum NOT NULL DEFAULT 'n',

CONSTRAINT pk_schedule PRIMARY KEY (id)
);

CREATE INDEX idx_schedule_changed_at ON schedule(changed_at);

CREATE TRIGGER trg_schedule_incr_cfg_update
BEFORE INSERT OR UPDATE ON schedule
FOR EACH ROW
EXECUTE FUNCTION incr_cfg_bump_changed_at();

CREATE TABLE timeperiod (
id bigserial,
owned_by_schedule_id bigint REFERENCES schedule(id), -- nullable for future standalone timeperiods

changed_at bigint NOT NULL DEFAULT extract(epoch from now()) * 1000,
changed_at bigint NOT NULL DEFAULT EXTRACT(EPOCH FROM NOW()) * 1000,
deleted boolenum NOT NULL DEFAULT 'n',

CONSTRAINT pk_timeperiod PRIMARY KEY (id)
);

CREATE INDEX idx_timeperiod_changed_at ON timeperiod(changed_at);

CREATE TRIGGER trg_timeperiod_incr_cfg_update
BEFORE INSERT OR UPDATE ON timeperiod
FOR EACH ROW
EXECUTE FUNCTION incr_cfg_bump_changed_at();

-- Changes to timeperiod_entry should be notified by an updated timeperiod.changed_at.
CREATE TABLE timeperiod_entry (
id bigserial,
Expand All @@ -147,6 +244,11 @@ CREATE TABLE timeperiod_entry (
CONSTRAINT pk_timeperiod_entry PRIMARY KEY (id)
);

CREATE TRIGGER trg_timeperiod_entry_changed_at_relation
AFTER INSERT OR UPDATE OR DELETE ON timeperiod_entry
FOR EACH ROW
EXECUTE FUNCTION incr_cfg_bump_changed_at_relation('timeperiod');

-- Changes to schedule_member should be notified by an updated schedule.changed_at.
CREATE TABLE schedule_member (
schedule_id bigint NOT NULL REFERENCES schedule(id),
Expand All @@ -164,6 +266,11 @@ CREATE TABLE schedule_member (
CHECK (num_nonnulls(contact_id, contactgroup_id) = 1)
);

CREATE TRIGGER trg_schedule_member_changed_at_relation
AFTER INSERT OR UPDATE OR DELETE ON schedule_member
FOR EACH ROW
EXECUTE FUNCTION incr_cfg_bump_changed_at_relation('schedule');

CREATE TABLE source (
id bigserial,
-- The type "icinga2" is special and requires (at least some of) the icinga2_ prefixed columns.
Expand All @@ -189,7 +296,7 @@ CREATE TABLE source (
icinga2_common_name text,
icinga2_insecure_tls boolenum NOT NULL DEFAULT 'n',

changed_at bigint NOT NULL DEFAULT extract(epoch from now()) * 1000,
changed_at bigint NOT NULL DEFAULT EXTRACT(EPOCH FROM NOW()) * 1000,
deleted boolenum NOT NULL DEFAULT 'n',

-- The hash is a PHP password_hash with PASSWORD_DEFAULT algorithm, defaulting to bcrypt. This check roughly ensures
Expand All @@ -203,6 +310,11 @@ CREATE TABLE source (

CREATE INDEX idx_source_changed_at ON source(changed_at);

CREATE TRIGGER trg_source_incr_cfg_update
BEFORE INSERT OR UPDATE ON source
FOR EACH ROW
EXECUTE FUNCTION incr_cfg_bump_changed_at();

CREATE TABLE object (
id bytea NOT NULL, -- SHA256 of identifying tags and the source.id
source_id bigint NOT NULL REFERENCES source(id),
Expand Down Expand Up @@ -252,14 +364,19 @@ CREATE TABLE rule (
object_filter text,
is_active boolenum NOT NULL DEFAULT 'y',

changed_at bigint NOT NULL DEFAULT extract(epoch from now()) * 1000,
changed_at bigint NOT NULL DEFAULT EXTRACT(EPOCH FROM NOW()) * 1000,
deleted boolenum NOT NULL DEFAULT 'n',

CONSTRAINT pk_rule PRIMARY KEY (id)
);

CREATE INDEX idx_rule_changed_at ON rule(changed_at);

CREATE TRIGGER trg_rule_incr_cfg_update
BEFORE INSERT OR UPDATE ON rule
FOR EACH ROW
EXECUTE FUNCTION incr_cfg_bump_changed_at();

-- Changes to rule_escalation should be notified by an updated rule.changed_at.
CREATE TABLE rule_escalation (
id bigserial,
Expand All @@ -275,6 +392,11 @@ CREATE TABLE rule_escalation (
CHECK (NOT (condition IS NOT NULL AND fallback_for IS NOT NULL))
);

CREATE TRIGGER trg_rule_escalation_changed_at_relation
AFTER INSERT OR UPDATE OR DELETE ON rule_escalation
FOR EACH ROW
EXECUTE FUNCTION incr_cfg_bump_changed_at_relation('rule');

-- Changes to rule_escalation_recipient should be notified by an updated rule.changed_at via rule_escalation.rule_id.
CREATE TABLE rule_escalation_recipient (
id bigserial,
Expand All @@ -289,6 +411,11 @@ CREATE TABLE rule_escalation_recipient (
CHECK (num_nonnulls(contact_id, contactgroup_id, schedule_id) = 1)
);

CREATE TRIGGER trg_rule_escalation_recipient_changed_at_relation
AFTER INSERT OR UPDATE OR DELETE ON rule_escalation_recipient
FOR EACH ROW
EXECUTE FUNCTION incr_cfg_bump_changed_at_relation_2nd('rule_escalation', 'rule');

CREATE TABLE incident (
id bigserial,
object_id bytea NOT NULL REFERENCES object(id),
Expand Down
Loading

0 comments on commit 433760f

Please sign in to comment.