From 144f118d5459b490614abc60e721c96cac919bab Mon Sep 17 00:00:00 2001 From: Lorenz Stechauner Date: Sat, 29 Apr 2023 01:30:48 +0200 Subject: [PATCH] Add ctime and mtime for specific tables --- sql/v01/10.create.sql | 22 ++- sql/v01/11.timestamp-trigger.sql | 256 +++++++++++++++++++++++++++++++ 2 files changed, 272 insertions(+), 6 deletions(-) create mode 100644 sql/v01/11.timestamp-trigger.sql diff --git a/sql/v01/10.create.sql b/sql/v01/10.create.sql index 44dcf85..2286c4f 100644 --- a/sql/v01/10.create.sql +++ b/sql/v01/10.create.sql @@ -310,7 +310,10 @@ CREATE TABLE member ( default_kgnr INTEGER CHECK (NOT active OR default_kgnr IS NOT NULL), contact_postal INTEGER NOT NULL CHECK (contact_postal IN (TRUE, FALSE)) DEFAULT TRUE, contact_email INTEGER NOT NULL CHECK (contact_email IN (TRUE, FALSE)) DEFAULT FALSE, - comment TEXT DEFAULT NULL, + + comment TEXT DEFAULT NULL, + ctime INTEGER NOT NULL DEFAULT (UNIXEPOCH()), + mtime INTEGER NOT NULL DEFAULT (UNIXEPOCH()), CONSTRAINT pk_member PRIMARY KEY (mgnr), CONSTRAINT fk_member_member FOREIGN KEY (predecessor_mgnr) REFERENCES member (mgnr) @@ -351,7 +354,10 @@ CREATE TABLE contract ( date TEXT CHECK (date REGEXP '^[1-9][0-9]{3}-(0[1-9]|1[012])-(0[1-9]|[12][0-9]|3[01])$') DEFAULT CURRENT_DATE, year_from INTEGER CHECK (year_from >= 1000 AND year_from <= 9999) DEFAULT NULL, year_to INTEGER CHECK (year_to >= 1000 AND year_to <= 9999) DEFAULT NULL, - comment TEXT DEFAULT NULL, + + comment TEXT DEFAULT NULL, + ctime INTEGER NOT NULL DEFAULT (UNIXEPOCH()), + mtime INTEGER NOT NULL DEFAULT (UNIXEPOCH()), CONSTRAINT pk_contract PRIMARY KEY (vnr), CONSTRAINT fk_contract_member FOREIGN KEY (mgnr) REFERENCES member (mgnr) @@ -459,7 +465,9 @@ CREATE TABLE delivery ( mgnr INTEGER NOT NULL, - comment TEXT DEFAULT NULL, + comment TEXT DEFAULT NULL, + ctime INTEGER NOT NULL DEFAULT (UNIXEPOCH()), + mtime INTEGER NOT NULL DEFAULT (UNIXEPOCH()), CONSTRAINT pk_delivery PRIMARY KEY (year, did), CONSTRAINT sk_delivery_1 UNIQUE (date, zwstid, lnr), @@ -505,13 +513,15 @@ CREATE TABLE delivery_part ( hand_picked INTEGER CHECK (hand_picked IN (TRUE, FALSE)) DEFAULT NULL, lesewagen INTEGER CHECK (lesewagen IN (True, FALSE)) DEFAULT NULL, - temperature REAL DEFAULT NULL, - acid REAL DEFAULT NULL, + temperature REAL DEFAULT NULL, + acid REAL DEFAULT NULL, scale_id TEXT, weighing_id TEXT, - comment TEXT DEFAULT NULL, + comment TEXT DEFAULT NULL, + ctime INTEGER NOT NULL DEFAULT (UNIXEPOCH()), + mtime INTEGER NOT NULL DEFAULT (UNIXEPOCH()), CONSTRAINT pk_delivery_part PRIMARY KEY (year, did, dpnr), CONSTRAINT fk_delivery_part_delivery FOREIGN KEY (year, did) REFERENCES delivery (year, did) diff --git a/sql/v01/11.timestamp-trigger.sql b/sql/v01/11.timestamp-trigger.sql new file mode 100644 index 0000000..0216f35 --- /dev/null +++ b/sql/v01/11.timestamp-trigger.sql @@ -0,0 +1,256 @@ + +CREATE TRIGGER t_member_i_ctime + AFTER INSERT ON member FOR EACH ROW + WHEN NEW.ctime != UNIXEPOCH() +BEGIN + UPDATE member SET ctime = UNIXEPOCH() WHERE mgnr = NEW.mgnr; +END; + +CREATE TRIGGER t_member_u_ctime + BEFORE UPDATE ON member FOR EACH ROW + WHEN OLD.ctime != NEW.ctime +BEGIN + SELECT RAISE(ABORT, 'It is not allowed to change ctime'); +END; + +CREATE TRIGGER t_member_i_mtime + AFTER INSERT ON member FOR EACH ROW + WHEN NEW.mtime != UNIXEPOCH() +BEGIN + UPDATE member SET mtime = UNIXEPOCH() WHERE mgnr = NEW.mgnr; +END; + +CREATE TRIGGER t_member_u_mtime + AFTER UPDATE ON member FOR EACH ROW + WHEN NEW.mtime != UNIXEPOCH() +BEGIN + UPDATE member SET mtime = UNIXEPOCH() WHERE mgnr = NEW.mgnr; +END; + +---------------------------------------------------------------- + +CREATE TRIGGER t_member_billing_address_i_mtime_member + AFTER INSERT ON member_billing_address FOR EACH ROW +BEGIN + UPDATE member SET mtime = UNIXEPOCH() WHERE mgnr = NEW.mgnr; +END; + +CREATE TRIGGER t_member_billing_address_u_mtime_member + AFTER UPDATE ON member_billing_address FOR EACH ROW +BEGIN + UPDATE member SET mtime = UNIXEPOCH() WHERE mgnr = OLD.mgnr OR mgnr = NEW.mgnr; +END; + +CREATE TRIGGER t_member_billing_address_d_mtime_member + AFTER DELETE ON member_billing_address FOR EACH ROW +BEGIN + UPDATE member SET mtime = UNIXEPOCH() WHERE mgnr = OLD.mgnr; +END; + +---------------------------------------------------------------- + +CREATE TRIGGER t_contract_i_ctime + AFTER INSERT ON contract FOR EACH ROW + WHEN NEW.ctime != UNIXEPOCH() +BEGIN + UPDATE contract SET ctime = UNIXEPOCH() WHERE vnr = NEW.vnr; +END; + +CREATE TRIGGER t_contract_u_ctime + BEFORE UPDATE ON contract FOR EACH ROW + WHEN OLD.ctime != NEW.ctime +BEGIN + SELECT RAISE(ABORT, 'It is not allowed to change ctime'); +END; + +CREATE TRIGGER t_contract_i_mtime + AFTER INSERT ON contract FOR EACH ROW + WHEN NEW.mtime != UNIXEPOCH() +BEGIN + UPDATE contract SET mtime = UNIXEPOCH() WHERE vnr = NEW.vnr; +END; + +CREATE TRIGGER t_contract_u_mtime + AFTER UPDATE ON contract FOR EACH ROW + WHEN NEW.mtime != UNIXEPOCH() +BEGIN + UPDATE contract SET mtime = UNIXEPOCH() WHERE vnr = NEW.vnr; +END; + +---------------------------------------------------------------- + +CREATE TRIGGER t_area_commitment_i_mtime_contract + AFTER INSERT ON area_commitment FOR EACH ROW +BEGIN + UPDATE contract SET mtime = UNIXEPOCH() WHERE vnr = NEW.vnr; +END; + +CREATE TRIGGER t_area_commitment_u_mtime_contract + AFTER UPDATE ON area_commitment FOR EACH ROW +BEGIN + UPDATE contract SET mtime = UNIXEPOCH() WHERE vnr = OLD.vnr OR vnr = NEW.vnr; +END; + +CREATE TRIGGER t_area_commitment_d_mtime_contract + AFTER DELETE ON area_commitment FOR EACH ROW +BEGIN + UPDATE contract SET mtime = UNIXEPOCH() WHERE vnr = OLD.vnr; +END; + +---------------------------------------------------------------- + +CREATE TRIGGER t_area_commitment_parcel_i_mtime_contract + AFTER INSERT ON area_commitment_parcel FOR EACH ROW +BEGIN + UPDATE contract SET mtime = UNIXEPOCH() WHERE vnr = NEW.vnr; +END; + +CREATE TRIGGER t_area_commitment_parcel_u_mtime_contract + AFTER UPDATE ON area_commitment_parcel FOR EACH ROW +BEGIN + UPDATE contract SET mtime = UNIXEPOCH() WHERE vnr = OLD.vnr OR vnr = NEW.vnr; +END; + +CREATE TRIGGER t_area_commitment_parcel_d_mtime_contract + AFTER DELETE ON area_commitment_parcel FOR EACH ROW +BEGIN + UPDATE contract SET mtime = UNIXEPOCH() WHERE vnr = OLD.vnr; +END; + +---------------------------------------------------------------- + +CREATE TRIGGER t_area_commitment_attribute_i_mtime_contract + AFTER INSERT ON area_commitment_attribute FOR EACH ROW +BEGIN + UPDATE contract SET mtime = UNIXEPOCH() WHERE vnr = NEW.vnr; +END; + +CREATE TRIGGER t_area_commitment_attribute_u_mtime_contract + AFTER UPDATE ON area_commitment_attribute FOR EACH ROW +BEGIN + UPDATE contract SET mtime = UNIXEPOCH() WHERE vnr = OLD.vnr OR vnr = NEW.vnr; +END; + +CREATE TRIGGER t_area_commitment_attribute_d_mtime_contract + AFTER DELETE ON area_commitment_attribute FOR EACH ROW +BEGIN + UPDATE contract SET mtime = UNIXEPOCH() WHERE vnr = OLD.vnr; +END; + +---------------------------------------------------------------- + +CREATE TRIGGER t_delivery_i_ctime + AFTER INSERT ON delivery FOR EACH ROW + WHEN NEW.ctime != UNIXEPOCH() +BEGIN + UPDATE delivery SET ctime = UNIXEPOCH() WHERE (year, did) = (NEW.year, NEW.did); +END; + +CREATE TRIGGER t_delivery_u_ctime + AFTER UPDATE ON delivery FOR EACH ROW + WHEN OLD.ctime != NEW.ctime +BEGIN + SELECT RAISE(ABORT, 'It is not allowed to change ctime'); +END; + +CREATE TRIGGER t_delivery_i_mtime + AFTER INSERT ON delivery FOR EACH ROW + WHEN NEW.mtime != UNIXEPOCH() +BEGIN + UPDATE delivery SET mtime = UNIXEPOCH() WHERE (year, did) = (NEW.year, NEW.did); +END; + +CREATE TRIGGER t_delivery_u_mtime + AFTER UPDATE ON delivery FOR EACH ROW + WHEN NEW.mtime != UNIXEPOCH() +BEGIN + UPDATE delivery SET mtime = UNIXEPOCH() WHERE (year, did) = (NEW.year, NEW.did); +END; + +---------------------------------------------------------------- + +CREATE TRIGGER t_delivery_part_i_ctime + AFTER INSERT ON delivery_part FOR EACH ROW + WHEN NEW.ctime != UNIXEPOCH() +BEGIN + UPDATE delivery_part SET ctime = UNIXEPOCH() WHERE (year, did, dpnr) = (NEW.year, NEW.did, NEW.dpnr); +END; + +CREATE TRIGGER t_delivery_part_u_ctime + AFTER UPDATE ON delivery_part FOR EACH ROW + WHEN OLD.ctime != NEW.ctime +BEGIN + SELECT RAISE(ABORT, 'It is not allowed to change ctime'); +END; + +CREATE TRIGGER t_delivery_part_i_mtime + AFTER INSERT ON delivery_part FOR EACH ROW + WHEN NEW.mtime != UNIXEPOCH() +BEGIN + UPDATE delivery_part SET mtime = UNIXEPOCH() WHERE (year, did, dpnr) = (NEW.year, NEW.did, NEW.dpnr); +END; + +CREATE TRIGGER t_delivery_part_u_mtime + AFTER UPDATE ON delivery_part FOR EACH ROW + WHEN NEW.mtime != UNIXEPOCH() +BEGIN + UPDATE delivery_part SET mtime = UNIXEPOCH() WHERE (year, did, dpnr) = (NEW.year, NEW.did, NEW.dpnr); +END; + +CREATE TRIGGER t_delivery_part_i_mtime_delivery + AFTER INSERT ON delivery_part FOR EACH ROW +BEGIN + UPDATE delivery SET mtime = UNIXEPOCH() WHERE (year, did) = (NEW.year, NEW.did); +END; + +CREATE TRIGGER t_delivery_part_u_mtime_delivery + AFTER UPDATE ON delivery_part FOR EACH ROW +BEGIN + UPDATE delivery SET mtime = UNIXEPOCH() WHERE (year, did) = (NEW.year, NEW.did) OR (year, did) = (OLD.year, OLD.did); +END; + +CREATE TRIGGER t_delivery_part_d_mtime_delivery + AFTER DELETE ON delivery_part FOR EACH ROW +BEGIN + UPDATE delivery SET mtime = UNIXEPOCH() WHERE (year, did) = (OLD.year, OLD.did); +END; + +---------------------------------------------------------------- + +CREATE TRIGGER t_delivery_part_attribute_i_mtime_delivery_part + AFTER INSERT ON delivery_part_attribute FOR EACH ROW +BEGIN + UPDATE delivery_part SET mtime = UNIXEPOCH() WHERE (year, did, dpnr) = (NEW.year, NEW.did, NEW.dpnr); +END; + +CREATE TRIGGER t_delivery_part_attribute_u_mtime_delivery_part + AFTER UPDATE ON delivery_part_attribute FOR EACH ROW +BEGIN + UPDATE delivery_part SET mtime = UNIXEPOCH() WHERE (year, did, dpnr) = (NEW.year, NEW.did, NEW.dpnr) OR (year, did, dpnr) = (OLD.year, OLD.did, OLD.dpnr); +END; + +CREATE TRIGGER t_delivery_part_attribute_d_mtime_delivery_part + AFTER DELETE ON delivery_part_attribute FOR EACH ROW +BEGIN + UPDATE delivery_part SET mtime = UNIXEPOCH() WHERE (year, did, dpnr) = (OLD.year, OLD.did, OLD.dpnr); +END; + +---------------------------------------------------------------- + +CREATE TRIGGER t_delivery_part_modifier_i_mtime_delivery_part + AFTER INSERT ON delivery_part_modifier FOR EACH ROW +BEGIN + UPDATE delivery_part SET mtime = UNIXEPOCH() WHERE (year, did, dpnr) = (NEW.year, NEW.did, NEW.dpnr); +END; + +CREATE TRIGGER t_delivery_part_modifier_u_mtime_delivery_part + AFTER UPDATE ON delivery_part_modifier FOR EACH ROW +BEGIN + UPDATE delivery_part SET mtime = UNIXEPOCH() WHERE (year, did, dpnr) = (NEW.year, NEW.did, NEW.dpnr) OR (year, did, dpnr) = (OLD.year, OLD.did, OLD.dpnr); +END; + +CREATE TRIGGER t_delivery_part_modifier_d_mtime_delivery_part + AFTER DELETE ON delivery_part_modifier FOR EACH ROW +BEGIN + UPDATE delivery_part SET mtime = UNIXEPOCH() WHERE (year, did, dpnr) = (OLD.year, OLD.did, OLD.dpnr); +END;