-- schema version 21 to 22

CREATE VIEW v_penalty_business_shares AS
SELECT u.year, u.mgnr,
       SUM(IIF(u.weight = 0, COALESCE(-s.penalty_none, 0) + COALESCE(-u.business_shares * s.penalty_per_bs_none, 0), 0) +
           IIF(u.diff < 0, COALESCE(-s.penalty_amount, 0), 0) +
           COALESCE(u.diff * s.penalty_per_kg, 0) + COALESCE(CEIL(CAST(u.diff AS REAL) / s.min_kg_per_bs) * s.penalty_per_bs_amount, 0)
       ) AS total_penalty
FROM v_total_under_delivery u
    JOIN season s ON u.year = s.year
    JOIN member m ON m.mgnr = u.mgnr
WHERE m.active
GROUP BY u.year, u.mgnr
HAVING total_penalty < 0
ORDER BY u.year, u.mgnr;

DROP VIEW v_penalty_area_commitments;
CREATE VIEW v_penalty_area_commitments AS
SELECT u.year, u.mgnr,
       SUM(COALESCE(IIF(u.weight = 0, -t.penalty_none, 0), 0) +
           COALESCE(IIF(u.diff < 0, -t.penalty_amount, 0), 0) +
           COALESCE(u.diff * t.penalty_per_kg, 0)
       ) AS total_penalty
FROM v_under_delivery u
   JOIN area_commitment_type t ON t.vtrgid = u.bucket
GROUP BY year, mgnr
HAVING total_penalty < 0
ORDER BY year, mgnr;

-- all values in the table are stored with precision 2!
CREATE TABLE payment_custom (
    year    INTEGER NOT NULL,
    mgnr    INTEGER NOT NULL,

    amount  INTEGER NOT NULL,
    comment TEXT,

    CONSTRAINT pk_payment_custom PRIMARY KEY (year, mgnr),
    CONSTRAINT fk_payment_custom_season FOREIGN KEY (year) REFERENCES season (year)
        ON UPDATE CASCADE
        ON DELETE CASCADE,
    CONSTRAINT fk_payment_custom_member FOREIGN KEY (mgnr) REFERENCES member (mgnr)
        ON UPDATE CASCADE
        ON DELETE CASCADE
) STRICT;