-- schema version 12 to 13

ALTER TABLE season ADD COLUMN bs_value INTEGER;

CREATE TABLE member_history (
    mgnr            INTEGER 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,

    business_shares INTEGER NOT NULL,
    type            TEXT    NOT NULL CHECK (type REGEXP '^[a-z_]+$'),
    comment         TEXT DEFAULT NULL,

    CONSTRAINT pk_member_history PRIMARY KEY (mgnr, date),
    CONSTRAINT fk_member_history_member FOREIGN KEY (mgnr) REFERENCES member (mgnr)
        ON UPDATE CASCADE
        ON DELETE CASCADE
) STRICT;

CREATE VIEW v_total_under_delivery AS
SELECT s.year, m.mgnr, m.business_shares,
       m.business_shares * s.min_kg_per_bs AS min_kg,
       m.business_shares * s.max_kg_per_bs AS max_kg,
       COALESCE(d.sum, 0) AS weight,
       IIF(COALESCE(d.sum, 0) < m.business_shares * s.min_kg_per_bs,
           COALESCE(d.sum, 0) - m.business_shares * s.min_kg_per_bs,
           IIF(COALESCE(d.sum, 0) > m.business_shares * s.max_kg_per_bs,
               COALESCE(d.sum, 0) - m.business_shares * s.max_kg_per_bs,
               0)) AS diff
FROM member m, season s
    LEFT JOIN v_stat_member d ON (d.year, d.mgnr) = (s.year, m.mgnr)
ORDER BY s.year, m.mgnr;