Files
elwig-misc/sql/v01/30.create.view.sql

134 lines
5.2 KiB
SQL

CREATE VIEW v_plz AS
SELECT plz, p.dest AS bestimmungsort, g.name AS gemeinde, g.gkz, o.name AS ort, o.okz
FROM AT_gem g
JOIN AT_ort o ON o.gkz = g.gkz
JOIN AT_plz_dest p ON p.okz = o.okz;
CREATE VIEW v_virtual_season AS
SELECT year, max_kg_per_ha
FROM season
UNION
SELECT strftime('%Y', date()) + 0, (SELECT max_kg_per_ha FROM season ORDER BY year DESC LIMIT 1);
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;
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_stat_season AS
SELECT year,
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
ORDER BY year;
CREATE VIEW v_stat_sort AS
SELECT year, sortid,
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
ORDER BY year, sortid;
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;
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;
CREATE VIEW v_stat_member AS
SELECT year, mgnr,
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
FROM v_delivery
GROUP BY year, mgnr
ORDER BY year, mgnr;
CREATE VIEW v_bki_member AS
SELECT s.year, m.mgnr, m.lfbis_nr, m.family_name,
(COALESCE(m.prefix || ' ', '') || m.given_name || COALESCE(' ' || m.middle_names, '') || COALESCE(' ' || m.suffix, '')) AS name,
a.name AS billing_name, COALESCE(a.address, m.address) AS address,
COALESCE(a.country, m.country) AS country, COALESCE(a.postal_dest, m.postal_dest) AS postal_dest,
SUM(IIF(c.year_from <= s.year AND (c.year_to IS NULL OR c.year_to >= s.year), c.area, 0)) AS area
FROM season s, member m
LEFT JOIN member_billing_address a ON a.mgnr = m.mgnr
LEFT JOIN area_commitment c ON c.mgnr = m.mgnr
GROUP BY s.year, m.mgnr;
CREATE VIEW v_bki_delivery AS
SELECT m.lfbis_nr, m.family_name, m.name, m.billing_name,
m.address, plz.plz, IIF(INSTR(o.name, ',') = 0, o.name, SUBSTR(o.name, 1, INSTR(o.name, ',') - 1)) AS ort,
d.date, d.weight, v.type, v.sortid, d.qualid, d.year, d.hkid, d.kmw, d.oe,
m.area
FROM v_delivery d
JOIN v_bki_member m ON (m.year, m.mgnr) = (d.year, d.mgnr)
JOIN postal_dest pd ON (pd.country, pd.id) = (m.country, m.postal_dest)
LEFT JOIN AT_plz_dest ap ON (ap.country, ap.id) = (pd.country, pd.id)
LEFT JOIN AT_plz plz ON plz.plz = ap.plz
LEFT JOIN AT_ort o ON o.okz = ap.okz
JOIN wine_variety v ON v.sortid = d.sortid
ORDER BY d.date, d.time;
CREATE VIEW v_total_under_delivery AS
SELECT s.year, m.mgnr, m.business_shares,
m.business_shares * s.min_kg_per_bs AS min_kg,
m.business_shares * s.max_kg_per_bs AS max_kg,
COALESCE(d.sum, 0) AS weight,
IIF(COALESCE(d.sum, 0) < m.business_shares * s.min_kg_per_bs,
COALESCE(d.sum, 0) - m.business_shares * s.min_kg_per_bs,
IIF(COALESCE(d.sum, 0) > m.business_shares * s.max_kg_per_bs,
COALESCE(d.sum, 0) - m.business_shares * s.max_kg_per_bs,
0)) AS diff
FROM member m, season s
LEFT JOIN v_stat_member d ON (d.year, d.mgnr) = (s.year, m.mgnr)
ORDER BY s.year, m.mgnr;