151 lines
		
	
	
		
			6.0 KiB
		
	
	
	
		
			SQL
		
	
	
	
	
	
			
		
		
	
	
			151 lines
		
	
	
		
			6.0 KiB
		
	
	
	
		
			SQL
		
	
	
	
	
	
-- schema version 5 to 6
 | 
						|
 | 
						|
DROP VIEW IF EXISTS v_area_commitment;
 | 
						|
 | 
						|
PRAGMA writable_schema = ON;
 | 
						|
ALTER TABLE wine_attribute DROP COLUMN fill_lower_bins;
 | 
						|
ALTER TABLE wine_attribute ADD COLUMN strict INTEGER NOT NULL CHECK (strict IN (TRUE, FALSE)) DEFAULT FALSE;
 | 
						|
ALTER TABLE wine_attribute ADD COLUMN fill_lower INTEGER NOT NULL CHECK (fill_lower IN (0, 1, 2)) DEFAULT 0;
 | 
						|
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,
 | 
						|
       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;
 | 
						|
PRAGMA writable_schema = OFF;
 | 
						|
 | 
						|
DROP VIEW v_area_commitment_bin;
 | 
						|
DROP VIEW v_delivery_bin;
 | 
						|
DROP VIEW v_payment_bin;
 | 
						|
 | 
						|
ALTER TABLE area_commitment_type DROP COLUMN max_kg_per_ha;
 | 
						|
ALTER TABLE area_commitment_type ADD COLUMN penalty_per_kg INTEGER DEFAULT NULL;
 | 
						|
ALTER TABLE area_commitment_type ADD COLUMN penalty_none INTEGER DEFAULT NULL;
 | 
						|
 | 
						|
ALTER TABLE wine_cultivation ADD COLUMN description TEXT DEFAULT NULL;
 | 
						|
ALTER TABLE member ADD COLUMN organic INTEGER NOT NULL CHECK (organic IN (TRUE, FALSE)) DEFAULT FALSE;
 | 
						|
 | 
						|
ALTER TABLE season ADD COLUMN max_kg_per_ha INTEGER NOT NULL DEFAULT 10000;
 | 
						|
ALTER TABLE season ADD COLUMN vat_normal REAL NOT NULL DEFAULT 0.10;
 | 
						|
ALTER TABLE season ADD COLUMN vat_flatrate REAL NOT NULL DEFAULT 0.13;
 | 
						|
ALTER TABLE season ADD COLUMN min_kg_per_bs INTEGER NOT NULL DEFAULT 750;
 | 
						|
ALTER TABLE season ADD COLUMN max_kg_per_bs INTEGER NOT NULL DEFAULT 3000;
 | 
						|
ALTER TABLE season ADD COLUMN penalty_per_kg INTEGER DEFAULT NULL;
 | 
						|
ALTER TABLE season ADD COLUMN penalty_amount INTEGER DEFAULT NULL;
 | 
						|
ALTER TABLE season ADD COLUMN penalty_none INTEGER DEFAULT NULL;
 | 
						|
 | 
						|
DELETE FROM client_parameter WHERE param IN ('DELIVERY_RIGHT', 'DELIVERY_OBLIGATION', 'VAT_NORMAL', 'VAT_REDUCED', 'VAT_FLATRATE');
 | 
						|
 | 
						|
CREATE TABLE delivery_part_bucket (
 | 
						|
    year     INTEGER NOT NULL,
 | 
						|
    did      INTEGER NOT NULL,
 | 
						|
    dpnr     INTEGER NOT NULL,
 | 
						|
    bktnr    INTEGER NOT NULL,
 | 
						|
 | 
						|
    discr    TEXT    NOT NULL,
 | 
						|
    value    INTEGER NOT NULL,
 | 
						|
 | 
						|
    CONSTRAINT pk_delivery_part_bucket PRIMARY KEY (year, did, dpnr, bktnr),
 | 
						|
    CONSTRAINT fk_delivery_part_bucket_delivery_part FOREIGN KEY (year, did, dpnr) REFERENCES delivery_part (year, did, dpnr)
 | 
						|
        ON UPDATE CASCADE
 | 
						|
        ON DELETE CASCADE
 | 
						|
) STRICT;
 | 
						|
 | 
						|
INSERT INTO delivery_part_bucket (year, did, dpnr, bktnr, discr, value)
 | 
						|
SELECT year, did, dpnr, binnr, discr, value
 | 
						|
FROM delivery_part_bin;
 | 
						|
 | 
						|
DROP TABLE delivery_part_bin;
 | 
						|
 | 
						|
CREATE VIEW v_area_commitment_bucket_strict AS
 | 
						|
SELECT s.year, c.mgnr,
 | 
						|
        t.sortid || COALESCE(a.attrid, '') AS bucket,
 | 
						|
        t.sortid, a.attrid,
 | 
						|
        CAST(ROUND(SUM(area) * COALESCE(t.min_kg_per_ha, 0) / 10000.0, 0) AS INTEGER) AS min_kg,
 | 
						|
        CAST(ROUND(SUM(area) * MIN(COALESCE(a.max_kg_per_ha, s.max_kg_per_ha), s.max_kg_per_ha) / 10000.0, 0) AS INTEGER) AS max_kg,
 | 
						|
        CAST(ROUND(SUM(area) * s.max_kg_per_ha / 10000.0, 0) AS INTEGER) AS upper_max_kg
 | 
						|
FROM season s, area_commitment c
 | 
						|
    JOIN area_commitment_type t ON t.vtrgid = c.vtrgid
 | 
						|
    LEFT JOIN wine_attribute a ON a.attrid = t.attrid
 | 
						|
WHERE (year_from IS NULL OR year_from <= s.year) AND
 | 
						|
      (year_to IS NULL OR year_to >= s.year)
 | 
						|
GROUP BY s.year, c.mgnr, bucket
 | 
						|
ORDER BY s.year, c.mgnr, bucket;
 | 
						|
 | 
						|
CREATE VIEW v_area_commitment_bucket AS
 | 
						|
SELECT year, mgnr, bucket, min_kg, max_kg
 | 
						|
FROM v_area_commitment_bucket_strict
 | 
						|
WHERE attrid IS NOT NULL
 | 
						|
UNION ALL
 | 
						|
SELECT b.year, b.mgnr, b.sortid,
 | 
						|
       SUM(b.min_kg) AS min_kg,
 | 
						|
       SUM(b.upper_max_kg) AS max_kg
 | 
						|
FROM v_area_commitment_bucket_strict b
 | 
						|
    LEFT JOIN wine_attribute a ON a.attrid = b.attrid
 | 
						|
WHERE a.strict IS NULL OR a.strict = FALSE
 | 
						|
GROUP BY b.year, b.mgnr, b.sortid
 | 
						|
ORDER BY year, mgnr, bucket;
 | 
						|
 | 
						|
CREATE VIEW v_delivery_bucket_strict AS
 | 
						|
SELECT year, mgnr,
 | 
						|
       sortid || IIF(min_quw, COALESCE(attrid, ''), '_') AS bucket,
 | 
						|
       sortid, IIF(min_quw, attrid, NULL) AS attrid,
 | 
						|
       SUM(weight) AS weight,
 | 
						|
       min_quw
 | 
						|
FROM v_delivery
 | 
						|
GROUP BY year, mgnr, bucket
 | 
						|
ORDER BY year, mgnr, bucket;
 | 
						|
 | 
						|
CREATE VIEW v_delivery_bucket AS
 | 
						|
SELECT year, mgnr, bucket, weight
 | 
						|
FROM v_delivery_bucket_strict
 | 
						|
WHERE attrid IS NOT NULL OR NOT min_quw
 | 
						|
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 min_quw AND (a.strict IS NULL OR a.strict = FALSE)
 | 
						|
GROUP BY b.year, b.mgnr, b.sortid
 | 
						|
ORDER BY year, mgnr, bucket;
 | 
						|
 | 
						|
CREATE VIEW v_payment_bucket_strict AS
 | 
						|
SELECT d.year, d.mgnr,
 | 
						|
       d.sortid || b.discr AS bucket,
 | 
						|
       d.sortid, IIF(b.discr IN ('', '_'), NULL, b.discr) AS attrid,
 | 
						|
       SUM(b.value) AS weight,
 | 
						|
       b.discr != '_' AS gebunden
 | 
						|
FROM v_delivery d
 | 
						|
    LEFT JOIN delivery_part_bucket b ON (b.year, b.did, b.dpnr) = (d.year, d.did, d.dpnr)
 | 
						|
GROUP BY d.year, d.mgnr, bucket
 | 
						|
HAVING SUM(b.value) > 0
 | 
						|
ORDER BY d.year, d.mgnr, bucket;
 | 
						|
 | 
						|
CREATE VIEW v_payment_bucket AS
 | 
						|
SELECT year, mgnr, bucket, weight
 | 
						|
FROM v_payment_bucket_strict
 | 
						|
WHERE attrid IS NOT NULL OR NOT gebunden
 | 
						|
UNION ALL
 | 
						|
SELECT b.year, b.mgnr, b.sortid,
 | 
						|
       SUM(b.weight) AS weight
 | 
						|
FROM v_payment_bucket_strict b
 | 
						|
    LEFT JOIN wine_attribute a ON a.attrid = b.attrid
 | 
						|
WHERE gebunden AND (a.strict IS NULL OR a.strict = FALSE)
 | 
						|
GROUP BY b.year, b.mgnr, b.sortid
 | 
						|
ORDER BY year, mgnr, bucket;
 |