-- schema version 2 to 3 CREATE TABLE delivery_part_bin ( year INTEGER NOT NULL, did INTEGER NOT NULL, dpnr INTEGER NOT NULL, binnr INTEGER NOT NULL, discr TEXT NOT NULL, value INTEGER NOT NULL, CONSTRAINT pk_delivery_part_bin PRIMARY KEY (year, did, dpnr, binnr), CONSTRAINT fk_delivery_part_bin_delivery_part FOREIGN KEY (year, did, dpnr) REFERENCES delivery_part (year, did, dpnr) ON UPDATE CASCADE ON DELETE CASCADE ) STRICT; INSERT INTO delivery_part_bin (year, did, dpnr, binnr, discr, value) SELECT year, did, dpnr, 0, '_', bucket_2 + bucket_3 FROM payment_delivery_part WHERE COALESCE(bucket_1, bucket_2, bucket_3, bucket_4, bucket_5, bucket_6, bucket_7, bucket_8, bucket_9) IS NOT NULL ON CONFLICT DO NOTHING; INSERT INTO delivery_part_bin (year, did, dpnr, binnr, discr, value) SELECT d.year, d.did, d.dpnr, 1, COALESCE(attributes, ''), bucket_1 FROM payment_delivery_part p JOIN v_delivery d ON (d.year, d.did, d.dpnr) = (p.year, p.did, p.dpnr) WHERE COALESCE(bucket_1, bucket_2, bucket_3, bucket_4, bucket_5, bucket_6, bucket_7, bucket_8, bucket_9) IS NOT NULL ON CONFLICT DO NOTHING; ALTER TABLE payment_delivery_part DROP COLUMN bucket_1; ALTER TABLE payment_delivery_part DROP COLUMN bucket_2; ALTER TABLE payment_delivery_part DROP COLUMN bucket_3; ALTER TABLE payment_delivery_part DROP COLUMN bucket_4; ALTER TABLE payment_delivery_part DROP COLUMN bucket_5; ALTER TABLE payment_delivery_part DROP COLUMN bucket_6; ALTER TABLE payment_delivery_part DROP COLUMN bucket_7; ALTER TABLE payment_delivery_part DROP COLUMN bucket_8; ALTER TABLE payment_delivery_part DROP COLUMN bucket_9; ALTER TABLE payment_variant DROP COLUMN bucket_1_name; ALTER TABLE payment_variant DROP COLUMN bucket_2_name; ALTER TABLE payment_variant DROP COLUMN bucket_3_name; ALTER TABLE payment_variant DROP COLUMN bucket_4_name; ALTER TABLE payment_variant DROP COLUMN bucket_5_name; ALTER TABLE payment_variant DROP COLUMN bucket_6_name; ALTER TABLE payment_variant DROP COLUMN bucket_7_name; ALTER TABLE payment_variant DROP COLUMN bucket_8_name; ALTER TABLE payment_variant DROP COLUMN bucket_9_name; ALTER TABLE delivery_part ADD COLUMN gebunden INTEGER CHECK (gebunden IN (TRUE, FALSE)) DEFAULT NULL; DROP VIEW v_delivery; CREATE VIEW v_delivery AS SELECT s.*, GROUP_CONCAT(o.modid) AS modifiers FROM (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, 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, GROUP_CONCAT(a.attrid) AS attributes, COALESCE(SUM(a.fill_lower_bins), 0) AS attribute_prio, 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 delivery_part_attribute pa ON (pa.year, pa.did, pa.dpnr) = (p.year, p.did, p.dpnr) LEFT JOIN wine_attribute a ON a.attrid = pa.attrid GROUP BY p.year, p.did, p.dpnr ORDER BY p.year, p.did, p.dpnr, a.attrid) s LEFT JOIN delivery_part_modifier o ON (o.year, o.did, o.dpnr) = (s.year, s.did, s.dpnr) GROUP BY s.year, s.lsnr, s.dpnr ORDER BY s.year, s.lsnr, s.dpnr, o.modid; DROP VIEW v_bucket; CREATE VIEW v_delivery_bin AS SELECT year, mgnr, sortid || IIF(min_quw, REPLACE(COALESCE(attributes, ''), ',', ''), '_') AS bin, SUM(weight) AS weight FROM v_delivery GROUP BY year, mgnr, bin ORDER BY year, mgnr, LENGTH(bin) DESC, bin; CREATE VIEW v_payment_bin AS SELECT d.year, d.mgnr, sortid || discr AS bin, SUM(value) AS weight FROM v_delivery d JOIN delivery_part_bin b ON (b.year, b.did, b.dpnr) = (d.year, d.did, d.dpnr) GROUP BY d.year, d.mgnr, bin HAVING SUM(value) > 0 ORDER BY d.year, d.mgnr, bin; ALTER TABLE wine_attribute ADD COLUMN fill_lower_bins INTEGER NOT NULL CHECK (fill_lower_bins IN (0, 1, 2)) DEFAULT 0;