Database: Add credit table

This commit is contained in:
2023-09-12 22:53:38 +02:00
parent 88480c7fe9
commit 99dd825508
2 changed files with 63 additions and 3 deletions

View File

@ -646,6 +646,7 @@ CREATE TABLE payment_variant (
CONSTRAINT pk_payment PRIMARY KEY (year, avnr)
) STRICT;
-- all values in the table are stored with season-precision!
CREATE TABLE payment_delivery_part (
year INTEGER NOT NULL,
did INTEGER NOT NULL,
@ -710,16 +711,15 @@ BEGIN
WHERE (year, avnr, mgnr) = (OLD.year, OLD.avnr, (SELECT mgnr FROM delivery WHERE (year, did) = (OLD.year, OLD.did)));
END;
-- all values in the table are stored with season-precision!
CREATE TABLE payment_member (
year INTEGER NOT NULL,
avnr INTEGER NOT NULL,
mgnr INTEGER NOT NULL,
amount INTEGER NOT NULL,
tgnr INTEGER DEFAULT NULL,
CONSTRAINT pk_payment_member PRIMARY KEY (year, avnr, mgnr),
CONSTRAINT sk_payment_member_tgnr UNIQUE (year, tgnr),
CONSTRAINT fk_payment_member_payment_variant FOREIGN KEY (year, avnr) REFERENCES payment_variant (year, avnr)
ON UPDATE CASCADE
ON DELETE CASCADE,
@ -727,3 +727,33 @@ CREATE TABLE payment_member (
ON UPDATE CASCADE
ON DELETE CASCADE
) STRICT;
-- all values in the table are stored with precision 2!
CREATE TABLE credit (
year INTEGER NOT NULL,
tgnr INTEGER NOT NULL,
mgnr INTEGER NOT NULL,
avnr INTEGER NOT NULL,
net_amount INTEGER NOT NULL,
prev_net_amount INTEGER,
vat REAL NOT NULL,
vat_amount INTEGER NOT NULL GENERATED ALWAYS AS (ROUND((net_amount - COALESCE(prev_net_amount, 0)) * vat)) VIRTUAL,
gross_amount INTEGER NOT NULL GENERATED ALWAYS AS (net_amount - COALESCE(prev_net_amount, 0) + vat_amount) VIRTUAL,
modifiers INTEGER,
prev_modifiers INTEGER,
amount INTEGER NOT NULL GENERATED ALWAYS AS (gross_amount + COALESCE(modifiers, 0) - COALESCE(prev_modifiers, 0)) STORED,
ctime INTEGER NOT NULL DEFAULT (UNIXEPOCH()),
mtime INTEGER NOT NULL DEFAULT (UNIXEPOCH()),
CONSTRAINT pk_credit PRIMARY KEY (year, tgnr),
CONSTRAINT sk_credit_payment_member UNIQUE (year, avnr, mgnr),
CONSTRAINT fk_credit_member FOREIGN KEY (mgnr) REFERENCES member (mgnr)
ON UPDATE CASCADE
ON DELETE RESTRICT,
CONSTRAINT fk_credit_payment_member FOREIGN KEY (year, avnr, mgnr) REFERENCES payment_member (year, avnr, mgnr)
ON UPDATE CASCADE
ON DELETE RESTRICT
);

View File

@ -284,3 +284,33 @@ CREATE TRIGGER t_payment_member_d_mtime_payment_variant
BEGIN
UPDATE payment_variant SET mtime = UNIXEPOCH() WHERE (year, avnr) = (OLD.year, OLD.avnr);
END;
----------------------------------------------------------------
CREATE TRIGGER t_credit_i_ctime
AFTER INSERT ON credit FOR EACH ROW
WHEN NEW.ctime != UNIXEPOCH()
BEGIN
UPDATE credit SET ctime = UNIXEPOCH() WHERE (year, tgnr) = (NEW.year, NEW.tgnr);
END;
CREATE TRIGGER t_credit_u_ctime
BEFORE UPDATE ON credit FOR EACH ROW
WHEN OLD.ctime != NEW.ctime
BEGIN
SELECT RAISE(ABORT, 'It is not allowed to change ctime');
END;
CREATE TRIGGER t_credit_i_mtime
AFTER INSERT ON credit FOR EACH ROW
WHEN NEW.mtime != UNIXEPOCH()
BEGIN
UPDATE credit SET mtime = UNIXEPOCH() WHERE (year, tgnr) = (NEW.year, NEW.tgnr);
END;
CREATE TRIGGER t_credit_u_mtime
AFTER UPDATE ON credit FOR EACH ROW
WHEN NEW.mtime != UNIXEPOCH()
BEGIN
UPDATE credit SET mtime = UNIXEPOCH() WHERE (year, tgnr) = (NEW.year, NEW.tgnr);
END;