database: add payment triggers
This commit is contained in:
@ -34,14 +34,15 @@ CREATE TABLE payment_variant (
|
|||||||
|
|
||||||
-- all values in the table are stored with season-precision!
|
-- all values in the table are stored with season-precision!
|
||||||
CREATE TABLE payment_delivery_part (
|
CREATE TABLE payment_delivery_part (
|
||||||
year INTEGER NOT NULL,
|
year INTEGER NOT NULL,
|
||||||
did INTEGER NOT NULL,
|
did INTEGER NOT NULL,
|
||||||
dpnr INTEGER NOT NULL,
|
dpnr INTEGER NOT NULL,
|
||||||
avnr INTEGER NOT NULL,
|
avnr INTEGER NOT NULL,
|
||||||
|
|
||||||
mod_abs INTEGER NOT NULL DEFAULT 0,
|
net_amount INTEGER NOT NULL,
|
||||||
mod_rel REAL NOT NULL DEFAULT 0,
|
mod_abs INTEGER NOT NULL DEFAULT 0,
|
||||||
amount INTEGER NOT NULL,
|
mod_rel REAL NOT NULL DEFAULT 0,
|
||||||
|
amount INTEGER NOT NULL GENERATED ALWAYS AS (ROUND(net_amount * (1 + mod_rel) + mod_abs)) STORED,
|
||||||
|
|
||||||
CONSTRAINT pk_payment_delivery_part PRIMARY KEY (year, did, dpnr, avnr),
|
CONSTRAINT pk_payment_delivery_part PRIMARY KEY (year, did, dpnr, avnr),
|
||||||
CONSTRAINT fk_payment_delivery_part_delivery_part FOREIGN KEY (year, did, dpnr) REFERENCES delivery_part (year, did, dpnr)
|
CONSTRAINT fk_payment_delivery_part_delivery_part FOREIGN KEY (year, did, dpnr) REFERENCES delivery_part (year, did, dpnr)
|
||||||
@ -55,16 +56,19 @@ CREATE TABLE payment_delivery_part (
|
|||||||
CREATE TRIGGER t_payment_delivery_part_i
|
CREATE TRIGGER t_payment_delivery_part_i
|
||||||
AFTER INSERT ON payment_delivery_part FOR EACH ROW
|
AFTER INSERT ON payment_delivery_part FOR EACH ROW
|
||||||
BEGIN
|
BEGIN
|
||||||
INSERT INTO payment_member (year, avnr, mgnr, amount)
|
INSERT INTO payment_member (year, avnr, mgnr, net_amount)
|
||||||
VALUES (NEW.year, NEW.avnr, (SELECT mgnr FROM delivery WHERE (year, did) = (NEW.year, NEW.did)), NEW.amount)
|
VALUES (NEW.year, NEW.avnr, (SELECT mgnr FROM delivery WHERE (year, did) = (NEW.year, NEW.did)), NEW.amount)
|
||||||
ON CONFLICT DO UPDATE SET amount = amount + excluded.amount;
|
ON CONFLICT DO UPDATE SET net_amount = net_amount + excluded.net_amount;
|
||||||
END;
|
END;
|
||||||
|
|
||||||
CREATE TRIGGER t_payment_delivery_part_u
|
CREATE TRIGGER t_payment_delivery_part_u
|
||||||
AFTER UPDATE OF amount ON payment_delivery_part FOR EACH ROW
|
AFTER UPDATE OF amount ON payment_delivery_part FOR EACH ROW
|
||||||
BEGIN
|
BEGIN
|
||||||
UPDATE payment_member
|
UPDATE payment_member
|
||||||
SET amount = amount - OLD.amount + NEW.amount
|
SET net_amount = net_amount - OLD.amount
|
||||||
|
WHERE (year, avnr, mgnr) = (NEW.year, NEW.avnr, (SELECT mgnr FROM delivery WHERE (year, did) = (NEW.year, NEW.did)));
|
||||||
|
UPDATE payment_member
|
||||||
|
SET net_amount = net_amount + NEW.amount
|
||||||
WHERE (year, avnr, mgnr) = (NEW.year, NEW.avnr, (SELECT mgnr FROM delivery WHERE (year, did) = (NEW.year, NEW.did)));
|
WHERE (year, avnr, mgnr) = (NEW.year, NEW.avnr, (SELECT mgnr FROM delivery WHERE (year, did) = (NEW.year, NEW.did)));
|
||||||
END;
|
END;
|
||||||
|
|
||||||
@ -72,7 +76,7 @@ CREATE TRIGGER t_payment_delivery_part_d
|
|||||||
AFTER DELETE ON payment_delivery_part FOR EACH ROW
|
AFTER DELETE ON payment_delivery_part FOR EACH ROW
|
||||||
BEGIN
|
BEGIN
|
||||||
UPDATE payment_member
|
UPDATE payment_member
|
||||||
SET amount = amount - OLD.amount
|
SET net_amount = net_amount - OLD.amount
|
||||||
WHERE (year, avnr, mgnr) = (OLD.year, OLD.avnr, (SELECT mgnr FROM delivery WHERE (year, did) = (OLD.year, OLD.did)));
|
WHERE (year, avnr, mgnr) = (OLD.year, OLD.avnr, (SELECT mgnr FROM delivery WHERE (year, did) = (OLD.year, OLD.did)));
|
||||||
END;
|
END;
|
||||||
|
|
||||||
@ -96,13 +100,43 @@ CREATE TABLE payment_delivery_part_bucket (
|
|||||||
ON DELETE CASCADE
|
ON DELETE CASCADE
|
||||||
) STRICT;
|
) STRICT;
|
||||||
|
|
||||||
|
CREATE TRIGGER t_payment_delivery_part_bucket_i
|
||||||
|
AFTER INSERT ON payment_delivery_part_bucket FOR EACH ROW
|
||||||
|
BEGIN
|
||||||
|
INSERT INTO payment_delivery_part (year, did, dpnr, avnr, net_amount)
|
||||||
|
VALUES (NEW.year, NEW.did, NEW.dpnr, NEW.avnr, NEW.amount)
|
||||||
|
ON CONFLICT DO UPDATE SET net_amount = net_amount + NEW.amount;
|
||||||
|
END;
|
||||||
|
|
||||||
|
CREATE TRIGGER t_payment_delivery_part_bucket_u
|
||||||
|
AFTER UPDATE OF amount ON payment_delivery_part_bucket FOR EACH ROW
|
||||||
|
BEGIN
|
||||||
|
UPDATE payment_delivery_part
|
||||||
|
SET net_amount = net_amount - OLD.amount
|
||||||
|
WHERE (year, did, dpnr, avnr) = (NEW.year, NEW.did, NEW.dpnr, NEW.avnr);
|
||||||
|
UPDATE payment_delivery_part
|
||||||
|
SET net_amount = net_amount + NEW.amount
|
||||||
|
WHERE (year, did, dpnr, avnr) = (NEW.year, NEW.did, NEW.dpnr, NEW.avnr);
|
||||||
|
END;
|
||||||
|
|
||||||
|
CREATE TRIGGER t_payment_delivery_part_bucket_d
|
||||||
|
AFTER DELETE ON payment_delivery_part_bucket FOR EACH ROW
|
||||||
|
BEGIN
|
||||||
|
UPDATE payment_delivery_part
|
||||||
|
SET net_amount = net_amount - OLD.amount
|
||||||
|
WHERE (year, did, dpnr, avnr) = (OLD.year, OLD.did, OLD.dpnr, OLD.avnr);
|
||||||
|
END;
|
||||||
|
|
||||||
-- all values in the table are stored with season-precision!
|
-- all values in the table are stored with season-precision!
|
||||||
CREATE TABLE payment_member (
|
CREATE TABLE payment_member (
|
||||||
year INTEGER NOT NULL,
|
year INTEGER NOT NULL,
|
||||||
avnr INTEGER NOT NULL,
|
avnr INTEGER NOT NULL,
|
||||||
mgnr INTEGER NOT NULL,
|
mgnr INTEGER NOT NULL,
|
||||||
|
|
||||||
amount INTEGER NOT NULL,
|
net_amount INTEGER NOT NULL,
|
||||||
|
mod_abs INTEGER NOT NULL DEFAULT 0,
|
||||||
|
mod_rel REAL NOT NULL DEFAULT 0,
|
||||||
|
amount INTEGER NOT NULL GENERATED ALWAYS AS (ROUND(net_amount * (1 + mod_rel) + mod_rel)) STORED,
|
||||||
|
|
||||||
CONSTRAINT pk_payment_member PRIMARY KEY (year, avnr, mgnr),
|
CONSTRAINT pk_payment_member PRIMARY KEY (year, avnr, mgnr),
|
||||||
CONSTRAINT fk_payment_member_payment_variant FOREIGN KEY (year, avnr) REFERENCES payment_variant (year, avnr)
|
CONSTRAINT fk_payment_member_payment_variant FOREIGN KEY (year, avnr) REFERENCES payment_variant (year, avnr)
|
||||||
|
@ -1,3 +1,3 @@
|
|||||||
|
|
||||||
-- This value MUST NOT be changed while other connections are open!
|
-- This value MUST NOT be changed while other connections are open!
|
||||||
PRAGMA schema_version = 800;
|
PRAGMA schema_version = 900;
|
||||||
|
Reference in New Issue
Block a user