Files
elwig-misc/sql/v01/31.create.bucket-view.sql

105 lines
3.8 KiB
SQL

CREATE VIEW v_area_commitment_bucket_strict AS
SELECT s.year, c.mgnr,
t.sortid || COALESCE(a.attrid, '') AS bucket,
t.sortid, a.attrid,
SUM(area) AS area,
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 v_virtual_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, area, 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.area) AS area,
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;
CREATE VIEW v_under_delivery_bucket_strict AS
SELECT c.year, c.mgnr, c.bucket, c.min_kg, COALESCE(p.weight, 0) AS weight
FROM v_area_commitment_bucket_strict c
LEFT JOIN v_payment_bucket_strict p ON (p.year, p.mgnr, p.bucket) = (c.year, c.mgnr, c.bucket)
ORDER BY c.year, c.mgnr, c.bucket;
CREATE VIEW v_under_delivery_bucket AS
SELECT u.year, u.mgnr, u.bucket, u.min_kg,
u.weight + SUM(MAX(COALESCE(p.weight - s.min_kg, 0), 0)) AS weight
FROM v_under_delivery_bucket_strict u
LEFT JOIN v_payment_bucket_strict p ON (p.year, p.mgnr, p.sortid) = (u.year, u.mgnr, u.bucket) AND p.attrid IS NOT NULL
LEFT JOIN wine_attribute a ON a.attrid = p.attrid
LEFT JOIN v_area_commitment_bucket_strict s ON (s.year, s.mgnr, s.bucket) = (p.year, p.mgnr, p.bucket)
WHERE (p.gebunden IS NULL OR p.gebunden) AND (a.strict IS NULL OR a.strict = FALSE)
GROUP BY u.year, u.mgnr, u.bucket
ORDER BY u.year, u.mgnr, u.bucket;
CREATE VIEW v_under_delivery AS
SELECT year, mgnr, bucket, min_kg, weight, weight - min_kg AS diff
FROM v_under_delivery_bucket
WHERE diff < 0;