-- schema version 4 to 5 CREATE TABLE area_commitment_type_new ( vtrgid TEXT NOT NULL CHECK (vtrgid = sortid || COALESCE(attrid, '') || disc), sortid TEXT NOT NULL, attrid TEXT, disc TEXT DEFAULT NULL CHECK (disc REGEXP '^[A-Z0-9]+$'), min_kg_per_ha INTEGER, max_kg_per_ha INTEGER, penalty_amount INTEGER, CONSTRAINT pk_area_commitment_type PRIMARY KEY (vtrgid), CONSTRAINT sk_area_commitment_type_sort_attr UNIQUE (sortid, attrid, disc), CONSTRAINT fk_area_commitment_type_wine_variety FOREIGN KEY (sortid) REFERENCES wine_variety (sortid) ON UPDATE CASCADE ON DELETE RESTRICT, CONSTRAINT fk_area_commitment_type_wine_attribute FOREIGN KEY (attrid) REFERENCES wine_attribute (attrid) ON UPDATE CASCADE ON DELETE RESTRICT ) STRICT; INSERT INTO area_commitment_type_new (vtrgid, sortid, attrid, disc, min_kg_per_ha, max_kg_per_ha, penalty_amount) SELECT vtrgid, sortid, attrid_1, disc, min_kg_per_ha, max_kg_per_ha, penalty_amount FROM area_commitment_type; PRAGMA foreign_keys = OFF; PRAGMA writable_schema = ON; DROP TABLE area_commitment_type; ALTER TABLE area_commitment_type_new RENAME TO area_commitment_type; PRAGMA writable_schema = OFF; PRAGMA foreign_keys = ON; ALTER TABLE delivery_part ADD COLUMN attrid TEXT DEFAULT NULL REFERENCES wine_attribute (attrid) ON UPDATE CASCADE ON DELETE RESTRICT; UPDATE delivery_part SET attrid = (SELECT attrid FROM delivery_part_attribute a WHERE (delivery_part.year, delivery_part.did, delivery_part.dpnr) = (a.year, a.did, a.dpnr) ORDER BY attrid DESC LIMIT 1); DROP TRIGGER t_delivery_part_attribute_i_mtime_delivery_part; DROP TRIGGER t_delivery_part_attribute_u_mtime_delivery_part; DROP TRIGGER t_delivery_part_attribute_d_mtime_delivery_part; DROP TABLE delivery_part_attribute; DROP VIEW v_delivery; CREATE VIEW v_delivery AS SELECT p.year, p.did, p.dpnr, d.date, d.time, d.zwstid, d.lnr, d.lsnr, m.mgnr, m.family_name, m.given_name, p.sortid, a.attrid, p.weight, p.kmw, ROUND(p.kmw * (4.54 + 0.022 * p.kmw), 0) AS oe, p.qualid, p.hkid, p.kgnr, p.rdnr, p.gerebelt, p.gebunden, p.qualid IN (SELECT l.qualid FROM wine_quality_level l WHERE NOT l.predicate AND (p.kmw >= l.min_kmw OR l.min_kmw IS NULL) ORDER BY l.min_kmw DESC LIMIT 1,100) AS abgewertet, p.qualid NOT IN ('WEI', 'RSW', 'LDW') AS min_quw, COALESCE(a.fill_lower_bins, 0) AS attribute_prio, GROUP_CONCAT(o.modid) AS modifiers, d.comment, p.comment AS part_comment FROM delivery_part p JOIN delivery d ON (d.year, d.did) = (p.year, p.did) JOIN member m ON m.mgnr = d.mgnr LEFT JOIN wine_attribute a ON a.attrid = p.attrid LEFT JOIN delivery_part_modifier o ON (o.year, o.did, o.dpnr) = (p.year, p.did, p.dpnr) GROUP BY p.year, p.did, p.dpnr ORDER BY p.year, p.did, p.dpnr, o.modid; DROP VIEW v_delivery_bin; CREATE VIEW v_delivery_bin AS SELECT year, mgnr, sortid || IIF(min_quw, COALESCE(attrid, ''), '_') AS bin, SUM(weight) AS weight FROM v_delivery GROUP BY year, mgnr, bin ORDER BY year, mgnr, LENGTH(bin) DESC, bin; DROP VIEW v_stat_attr; CREATE VIEW v_stat_attr AS SELECT year, attrid, SUM(weight) as sum, ROUND(SUM(kmw * weight) / SUM(weight), 2) AS kmw, ROUND(SUM(oe * weight) / SUM(weight), 1) AS oe, COUNT(DISTINCT did) AS lieferungen, COUNT(DISTINCT mgnr) AS mitglieder FROM v_delivery GROUP BY year, attrid ORDER BY year, attrid; DROP VIEW v_stat_sort_attr; CREATE VIEW v_stat_sort_attr AS SELECT year, sortid, attrid, SUM(weight) as sum, ROUND(SUM(kmw * weight) / SUM(weight), 2) AS kmw, ROUND(SUM(oe * weight) / SUM(weight), 1) AS oe, COUNT(DISTINCT did) AS lieferungen, COUNT(DISTINCT mgnr) AS mitglieder FROM v_delivery GROUP BY year, sortid, attrid ORDER BY year, sortid, attrid;