Migrate payments
This commit is contained in:
@ -606,85 +606,105 @@ CREATE TABLE delivery_part_modifier (
|
||||
) STRICT;
|
||||
|
||||
CREATE TABLE payment_variant (
|
||||
year INTEGER NOT NULL,
|
||||
avnr INTEGER NOT NULL,
|
||||
year INTEGER NOT NULL,
|
||||
avnr INTEGER NOT NULL,
|
||||
|
||||
name TEXT NOT NULL,
|
||||
date TEXT NOT NULL CHECK (date REGEXP '^[1-9][0-9]{3}-(0[1-9]|1[012])-(0[1-9]|[12][0-9]|3[01])$') DEFAULT CURRENT_DATE,
|
||||
test_variant INTEGER NOT NULL CHECK (test_variant IN (TRUE, FALSE)),
|
||||
|
||||
bucket_1_name TEXT DEFAULT NULL,
|
||||
bucket_2_name TEXT DEFAULT NULL,
|
||||
bucket_3_name TEXT DEFAULT NULL,
|
||||
bucket_4_name TEXT DEFAULT NULL,
|
||||
bucket_5_name TEXT DEFAULT NULL,
|
||||
bucket_6_name TEXT DEFAULT NULL,
|
||||
bucket_7_name TEXT DEFAULT NULL,
|
||||
bucket_8_name TEXT DEFAULT NULL,
|
||||
bucket_9_name TEXT DEFAULT NULL,
|
||||
|
||||
comment TEXT DEFAULT NULL,
|
||||
data TEXT NOT NULL,
|
||||
|
||||
CONSTRAINT pk_payment PRIMARY KEY (year, avnr)
|
||||
) STRICT;
|
||||
|
||||
CREATE TABLE delivery_payment (
|
||||
CREATE TABLE payment_delivery (
|
||||
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,
|
||||
mod_abs INTEGER NOT NULL DEFAULT 0,
|
||||
mod_rel REAL NOT NULL DEFAULT 0,
|
||||
|
||||
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,
|
||||
bucket_1 INTEGER DEFAULT NULL,
|
||||
bucket_2 INTEGER DEFAULT NULL,
|
||||
bucket_3 INTEGER DEFAULT NULL,
|
||||
bucket_4 INTEGER DEFAULT NULL,
|
||||
bucket_5 INTEGER DEFAULT NULL,
|
||||
bucket_6 INTEGER DEFAULT NULL,
|
||||
bucket_7 INTEGER DEFAULT NULL,
|
||||
bucket_8 INTEGER DEFAULT NULL,
|
||||
bucket_9 INTEGER DEFAULT NULL,
|
||||
|
||||
price_1 INTEGER DEFAULT NULL,
|
||||
price_2 INTEGER DEFAULT NULL,
|
||||
price_3 INTEGER DEFAULT NULL,
|
||||
price_4 INTEGER DEFAULT NULL,
|
||||
price_5 INTEGER DEFAULT NULL,
|
||||
price_6 INTEGER DEFAULT NULL,
|
||||
price_7 INTEGER DEFAULT NULL,
|
||||
price_8 INTEGER DEFAULT NULL,
|
||||
price_9 INTEGER DEFAULT NULL,
|
||||
|
||||
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)
|
||||
CONSTRAINT pk_payment_delivery PRIMARY KEY (year, did, dpnr, avnr),
|
||||
CONSTRAINT fk_payment_delivery_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)
|
||||
CONSTRAINT fk_payment_delivery_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
|
||||
CREATE TRIGGER t_payment_delivery_i
|
||||
AFTER INSERT ON payment_delivery FOR EACH ROW
|
||||
BEGIN
|
||||
INSERT INTO member_payment (year, avnr, mgnr, amount)
|
||||
INSERT INTO payment_member (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
|
||||
CREATE TRIGGER t_payment_delivery_u
|
||||
AFTER UPDATE OF amount ON payment_delivery FOR EACH ROW
|
||||
BEGIN
|
||||
UPDATE member_payment
|
||||
UPDATE payment_member
|
||||
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
|
||||
CREATE TRIGGER t_payment_delivery_d
|
||||
AFTER DELETE ON payment_delivery FOR EACH ROW
|
||||
BEGIN
|
||||
UPDATE member_payment
|
||||
UPDATE payment_member
|
||||
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 (
|
||||
CREATE TABLE payment_member (
|
||||
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)
|
||||
CONSTRAINT pk_payment_member PRIMARY KEY (year, avnr, mgnr),
|
||||
CONSTRAINT fk_payment_member_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)
|
||||
CONSTRAINT fk_payment_member_member FOREIGN KEY (mgnr) REFERENCES member (mgnr)
|
||||
ON UPDATE CASCADE
|
||||
ON DELETE CASCADE
|
||||
) STRICT;
|
||||
|
Reference in New Issue
Block a user