181 lines
7.2 KiB
SQL
181 lines
7.2 KiB
SQL
|
|
CREATE TABLE delivery_part_bucket (
|
|
year INTEGER NOT NULL,
|
|
did INTEGER NOT NULL,
|
|
dpnr INTEGER NOT NULL,
|
|
bktnr INTEGER NOT NULL,
|
|
|
|
discr TEXT NOT NULL,
|
|
value INTEGER NOT NULL,
|
|
|
|
CONSTRAINT pk_delivery_part_bucket PRIMARY KEY (year, did, dpnr, bktnr),
|
|
CONSTRAINT fk_delivery_part_bucket_delivery_part FOREIGN KEY (year, did, dpnr) REFERENCES delivery_part (year, did, dpnr)
|
|
ON UPDATE CASCADE
|
|
ON DELETE CASCADE
|
|
) STRICT;
|
|
|
|
CREATE TABLE payment_variant (
|
|
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,
|
|
transfer_date TEXT CHECK (transfer_date REGEXP '^[1-9][0-9]{3}-(0[1-9]|1[012])-(0[1-9]|[12][0-9]|3[01])$'),
|
|
test_variant INTEGER NOT NULL CHECK (test_variant IN (TRUE, FALSE)),
|
|
calc_time INTEGER,
|
|
|
|
comment TEXT DEFAULT NULL,
|
|
data TEXT NOT NULL,
|
|
ctime INTEGER NOT NULL DEFAULT (UNIXEPOCH()),
|
|
mtime INTEGER NOT NULL DEFAULT (UNIXEPOCH()),
|
|
|
|
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,
|
|
dpnr INTEGER NOT NULL,
|
|
avnr 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_abs)) STORED,
|
|
|
|
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)
|
|
ON UPDATE CASCADE
|
|
ON DELETE CASCADE,
|
|
CONSTRAINT fk_payment_delivery_part_payment_variant FOREIGN KEY (year, avnr) REFERENCES payment_variant (year, avnr)
|
|
ON UPDATE CASCADE
|
|
ON DELETE CASCADE
|
|
) STRICT;
|
|
|
|
CREATE TRIGGER t_payment_delivery_part_i
|
|
AFTER INSERT ON payment_delivery_part FOR EACH ROW
|
|
BEGIN
|
|
INSERT INTO payment_member (year, avnr, mgnr, net_amount)
|
|
SELECT year, NEW.avnr, mgnr, NEW.amount FROM delivery WHERE (year, did) = (NEW.year, NEW.did)
|
|
ON CONFLICT DO UPDATE SET net_amount = net_amount + excluded.net_amount;
|
|
END;
|
|
|
|
CREATE TRIGGER t_payment_delivery_part_u
|
|
AFTER UPDATE ON payment_delivery_part FOR EACH ROW
|
|
BEGIN
|
|
UPDATE payment_member
|
|
SET net_amount = net_amount - OLD.amount
|
|
WHERE (year, avnr, mgnr) IN (SELECT year, OLD.avnr, mgnr FROM delivery WHERE (year, did) = (OLD.year, OLD.did));
|
|
INSERT INTO payment_member (year, avnr, mgnr, net_amount)
|
|
SELECT d.year, v.avnr, d.mgnr, NEW.amount
|
|
FROM delivery d, payment_variant v
|
|
WHERE (d.year, d.did) = (NEW.year, NEW.did) AND (v.year, v.avnr) = (NEW.year, NEW.avnr)
|
|
ON CONFLICT DO UPDATE SET net_amount = net_amount + excluded.net_amount;
|
|
END;
|
|
|
|
CREATE TRIGGER t_payment_delivery_part_d
|
|
AFTER DELETE ON payment_delivery_part FOR EACH ROW
|
|
BEGIN
|
|
UPDATE payment_member
|
|
SET net_amount = net_amount - OLD.amount
|
|
WHERE (year, avnr, mgnr) IN (SELECT year, OLD.avnr, mgnr FROM delivery WHERE (year, did) = (OLD.year, OLD.did));
|
|
END;
|
|
|
|
-- all values in the table are stored with season-precision!
|
|
CREATE TABLE payment_delivery_part_bucket (
|
|
year INTEGER NOT NULL,
|
|
did INTEGER NOT NULL,
|
|
dpnr INTEGER NOT NULL,
|
|
bktnr INTEGER NOT NULL,
|
|
avnr INTEGER NOT NULL,
|
|
|
|
price INTEGER NOT NULL,
|
|
amount INTEGER NOT NULL,
|
|
|
|
CONSTRAINT pk_payment_delivery_part_bucket PRIMARY KEY (year, did, dpnr, bktnr, avnr),
|
|
CONSTRAINT fk_payment_delivery_part_bucket_delivery_part_bucket FOREIGN KEY (year, did, dpnr, bktnr) REFERENCES delivery_part_bucket (year, did, dpnr, bktnr)
|
|
ON UPDATE CASCADE
|
|
ON DELETE RESTRICT,
|
|
CONSTRAINT fk_payment_delivery_part_bucket_payment_variant FOREIGN KEY (year, avnr) REFERENCES payment_variant (year, avnr)
|
|
ON UPDATE CASCADE
|
|
ON DELETE CASCADE
|
|
) 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 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);
|
|
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!
|
|
CREATE TABLE payment_member (
|
|
year INTEGER NOT NULL,
|
|
avnr INTEGER NOT NULL,
|
|
mgnr 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_abs)) STORED,
|
|
|
|
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_payment_member_member FOREIGN KEY (mgnr) REFERENCES member (mgnr)
|
|
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)) STORED,
|
|
gross_amount INTEGER NOT NULL GENERATED ALWAYS AS (net_amount - COALESCE(prev_net_amount, 0) + vat_amount) STORED,
|
|
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
|
|
) STRICT;
|