-- schema version 8 to 9

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 CASCADE,
    CONSTRAINT fk_payment_delivery_part_bucket_payment_variant FOREIGN KEY (year, avnr) REFERENCES payment_variant (year, avnr)
        ON UPDATE CASCADE
        ON DELETE CASCADE
) STRICT;

DROP TRIGGER IF EXISTS t_payment_delivery_part_i;
DROP TRIGGER IF EXISTS t_payment_delivery_part_u;
DROP TRIGGER IF EXISTS t_payment_delivery_part_d;
ALTER TABLE payment_delivery_part RENAME COLUMN amount TO net_amount;
ALTER TABLE payment_delivery_part ADD COLUMN amount INTEGER NOT NULL GENERATED ALWAYS AS (ROUND(net_amount * (1 + mod_rel) + mod_abs)) VIRTUAL;

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;

ALTER TABLE payment_member RENAME COLUMN amount TO net_amount;
ALTER TABLE payment_member ADD COLUMN mod_abs INTEGER NOT NULL DEFAULT 0;
ALTER TABLE payment_member ADD COLUMN mod_rel REAL NOT NULL DEFAULT 0;
ALTER TABLE payment_member ADD COLUMN amount INTEGER NOT NULL GENERATED ALWAYS AS (ROUND(net_amount * (1 + mod_rel) + mod_rel)) VIRTUAL;

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)
    VALUES (NEW.year, NEW.avnr, (SELECT mgnr FROM delivery WHERE (year, did) = (NEW.year, NEW.did)), NEW.amount)
    ON CONFLICT DO UPDATE SET net_amount = net_amount + excluded.net_amount;
END;

CREATE TRIGGER t_payment_delivery_part_u
    AFTER UPDATE OF amount ON payment_delivery_part FOR EACH ROW
BEGIN
    UPDATE payment_member
    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)));
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) = (OLD.year, OLD.avnr, (SELECT mgnr FROM delivery WHERE (year, did) = (OLD.year, OLD.did)));
END;