-- schema version 17 to 18

ALTER TABLE delivery_part ADD COLUMN cultid TEXT DEFAULT NULL;

PRAGMA writable_schema = ON;
UPDATE sqlite_schema SET sql = REPLACE(sql, CHAR(10) ||
    ') STRICT',
    ',' || CHAR(10) ||
    '    CONSTRAINT fk_delivery_part_wine_cultivation FOREIGN KEY (cultid) REFERENCES wine_cultivation (cultid)' || CHAR(10) ||
    '        ON UPDATE CASCADE' || CHAR(10) ||
    '        ON DELETE RESTRICT' || CHAR(10) ||
    ') STRICT')
WHERE type = 'table' AND name = 'delivery_part';
UPDATE sqlite_schema SET sql = REPLACE(sql, 'gerebelt  ', 'net_weight')
WHERE type = 'table' AND name = 'delivery_part';

UPDATE sqlite_schema SET sql = REPLACE(sql, 'CHECK (cultid REGEXP ''^[A-Z]+$'')', 'CHECK (cultid REGEXP ''^[A-Z][A-Z0-9]*$'')')
WHERE type = 'table' AND name = 'wine_cultivation';

UPDATE sqlite_schema SET sql = REPLACE(sql, 'cultid    TEXT    NOT NULL', 'cultid    TEXT             DEFAULT NULL')
WHERE type = 'table' AND name = 'area_commitment';

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.cultid,
       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.net_weight, 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,
       IIF(a.strict, COALESCE(a.fill_lower, 0), 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;

CREATE VIEW v_wine_attribute AS
SELECT a.attrid, name, active, max_kg_per_ha, strict, fill_lower,
       COUNT(t.attrid) > 0 AS area_com
FROM wine_attribute a
    LEFT JOIN area_commitment_type t ON t.attrid = a.attrid
GROUP BY a.attrid;

DROP VIEW v_delivery_bucket_strict;
CREATE VIEW v_delivery_bucket_strict AS
SELECT year, mgnr,
       sortid || IIF(min_quw OR NOT COALESCE(area_com, TRUE), COALESCE(a.attrid, ''), '_') AS bucket,
       sortid, IIF(min_quw OR NOT COALESCE(area_com, TRUE), a.attrid, NULL) AS attrid,
       SUM(weight) AS weight,
       min_quw OR NOT COALESCE(area_com, TRUE) AS valid
FROM v_delivery d
    LEFT JOIN v_wine_attribute a ON a.attrid = d.attrid
GROUP BY year, mgnr, bucket
ORDER BY year, mgnr, bucket;

DROP VIEW v_delivery_bucket;
CREATE VIEW v_delivery_bucket AS
SELECT year, mgnr, bucket, weight
FROM v_delivery_bucket_strict
WHERE attrid IS NOT NULL OR NOT valid
UNION ALL
SELECT b.year, b.mgnr, b.sortid,
       SUM(b.weight) AS weight
FROM v_delivery_bucket_strict b
    LEFT JOIN wine_attribute a ON a.attrid = b.attrid
WHERE valid AND (a.strict IS NULL OR a.strict = FALSE)
GROUP BY b.year, b.mgnr, b.sortid
ORDER BY year, mgnr, bucket;

PRAGMA schema_version = 1701;
PRAGMA writable_schema = OFF;

----------------------------------------------------------------

UPDATE area_commitment SET cultid = NULL WHERE cultid = 'N';
DELETE FROM wine_cultivation WHERE cultid = 'N';
UPDATE wine_cultivation SET cultid = 'B', name = 'Bio', description = 'AT-BIO-302' WHERE cultid = 'BIO';
UPDATE wine_cultivation SET description = 'Kontrollierte Integrierte Produktion' WHERE cultid = 'KIP';

UPDATE area_commitment SET cultid = 'B', vtrgid = SUBSTR(vtrgid, 1, 2) WHERE vtrgid LIKE '__B';
UPDATE area_commitment SET cultid = 'B' WHERE vtrgid LIKE '__HU';
DELETE FROM area_commitment_type WHERE attrid = 'B';
UPDATE delivery_part SET cultid = 'B', attrid = NULL WHERE attrid = 'B';
UPDATE delivery_part SET cultid = 'B' WHERE attrid = 'HU';
DELETE FROM wine_attribute WHERE attrid = 'B';
UPDATE wine_attribute SET name = 'Huber' WHERE attrid = 'HU';
UPDATE wine_attribute SET max_kg_per_ha = NULL WHERE max_kg_per_ha = 10000;

UPDATE payment_variant SET data = REPLACE(REPLACE(REPLACE(data, '/B', '-B'), '/"', '"'), '/-', '-');