Add Abrechnung

This commit is contained in:
2023-02-16 19:12:46 +01:00
parent 9ae3163c42
commit 17ed825bb5
4 changed files with 114 additions and 6 deletions

View File

@ -360,6 +360,7 @@ CREATE TABLE area_commitment (
CREATE TABLE season (
year INTEGER NOT NULL CHECK (year >= 1000 AND year <= 9999),
currency TEXT NOT NULL,
precision INTEGER NOT NULL DEFAULT 2,
start_date TEXT CHECK (start_date REGEXP '^[1-9][0-9]{3}-(0[1-9]|1[012])-(0[1-9]|[12][0-9]|3[01])$'),
end_date TEXT CHECK (end_date REGEXP '^[1-9][0-9]{3}-(0[1-9]|1[012])-(0[1-9]|[12][0-9]|3[01])$'),
@ -376,7 +377,7 @@ CREATE TABLE modifier (
name TEXT NOT NULL,
abs INTEGER,
rel INTEGER,
rel REAL,
standard INTEGER NOT NULL CHECK (standard IN (TRUE, FALSE)),
quick_select INTEGER NOT NULL CHECK (quick_select IN (TRUE, FALSE)),
@ -384,7 +385,8 @@ CREATE TABLE modifier (
CONSTRAINT pk_modifier PRIMARY KEY (year, mnr),
CONSTRAINT fk_modifier_season FOREIGN KEY (year) REFERENCES season (year)
ON UPDATE CASCADE
ON DELETE CASCADE
ON DELETE CASCADE,
CONSTRAINT c_modifier CHECK ((abs IS NOT NULL AND rel IS NULL) OR (abs IS NULL AND rel IS NOT NULL))
) STRICT;
CREATE TABLE delivery (
@ -432,6 +434,7 @@ CREATE TABLE delivery_part (
weight INTEGER NOT NULL,
kmw REAL NOT NULL,
qualid TEXT NOT NULL,
hkid TEXT NOT NULL,
kgnr INTEGER DEFAULT NULL,
@ -456,6 +459,9 @@ CREATE TABLE delivery_part (
CONSTRAINT fk_delivery_part_wine_attribute FOREIGN KEY (attrid) REFERENCES wine_attribute (attrid)
ON UPDATE CASCADE
ON DELETE RESTRICT,
CONSTRAINT fk_delivery_part_wine_quality FOREIGN KEY (qualid) REFERENCES wine_quality (qualid)
ON UPDATE CASCADE
ON DELETE RESTRICT,
CONSTRAINT fk_delivery_part_wine_origin FOREIGN KEY (hkid) REFERENCES wine_origin (hkid)
ON UPDATE CASCADE
ON DELETE RESTRICT,
@ -507,3 +513,87 @@ CREATE TABLE delivery_part_modifier (
ON UPDATE CASCADE
ON DELETE RESTRICT
) STRICT;
CREATE TABLE payment_variant (
year INTEGER NOT NULL,
avnr INTEGER NOT NULL,
CONSTRAINT pk_payment PRIMARY KEY (year, avnr)
) STRICT;
CREATE TABLE delivery_payment (
year INTEGER NOT NULL,
did INTEGER NOT NULL,
dpnr INTEGER NOT NULL,
avnr INTEGER NOT NULL,
bucket_1 INTEGER,
bucket_2 INTEGER,
bucket_3 INTEGER,
bucket_4 INTEGER,
bucket_5 INTEGER,
bucket_6 INTEGER,
bucket_7 INTEGER,
bucket_8 INTEGER,
bucket_9 INTEGER,
price_1 INTEGER,
price_2 INTEGER,
price_3 INTEGER,
price_4 INTEGER,
price_5 INTEGER,
price_6 INTEGER,
price_7 INTEGER,
price_8 INTEGER,
price_9 INTEGER,
amount INTEGER NOT NULL,
CONSTRAINT pk_delivery_payment PRIMARY KEY (year, did, dpnr),
CONSTRAINT fk_delivery_payment_delivery_part FOREIGN KEY (year, did, dpnr) REFERENCES delivery_part (year, did, dpnr)
ON UPDATE CASCADE
ON DELETE CASCADE,
CONSTRAINT fk_delivery_payment_payment_variant FOREIGN KEY (year, avnr) REFERENCES payment_variant (year, avnr)
ON UPDATE CASCADE
ON DELETE CASCADE
) STRICT;
CREATE TRIGGER t_delivery_payment_i
AFTER INSERT ON delivery_payment FOR EACH ROW
BEGIN
INSERT INTO member_payment (year, avnr, mgnr, 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 + NEW.amount;
END;
CREATE TRIGGER t_delivery_payment_u
AFTER UPDATE OF amount ON delivery_payment FOR EACH ROW
BEGIN
UPDATE member_payment
SET amount = amount - OLD.amount + NEW.amount
WHERE (year, avnr, mgnr) = (NEW.year, NEW.avnr, (SELECT mgnr FROM delivery WHERE (year, did) = (NEW.year, NEW.did)));
END;
CREATE TRIGGER t_delivery_payment_d
AFTER DELETE ON delivery_payment FOR EACH ROW
BEGIN
UPDATE member_payment
SET amount = amount - OLD.amount
WHERE (year, avnr, mgnr) = (OLD.year, OLD.avnr, (SELECT mgnr FROM delivery WHERE (year, did) = (OLD.year, OLD.did)));
END;
CREATE TABLE member_payment (
year INTEGER NOT NULL,
avnr INTEGER NOT NULL,
mgnr INTEGER NOT NULL,
amount INTEGER NOT NULL,
CONSTRAINT pk_member_payment PRIMARY KEY (year, avnr, mgnr),
CONSTRAINT fk_member_payment_payment_variant FOREIGN KEY (year, avnr) REFERENCES payment_variant (year, avnr)
ON UPDATE CASCADE
ON DELETE CASCADE,
CONSTRAINT fk_member_payment_member FOREIGN KEY (mgnr) REFERENCES member (mgnr)
ON UPDATE CASCADE
ON DELETE CASCADE
) STRICT;