Files
elwig-misc/sql/v01/20.view.sql

80 lines
2.8 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_contract AS
SELECT v.vnr, v.mgnr, v.year_from, v.year_to,
GROUP_CONCAT(DISTINCT p.kgnr || '-' || p.gstnr) AS gstnrs,
f.area, f.sortid,
GROUP_CONCAT(DISTINCT a.attrid) AS attributes,
f.cultid,
v.comment
FROM contract v
LEFT JOIN area_commitment f ON f.vnr = v.vnr
LEFT JOIN area_commitment_parcel p ON p.vnr = f.vnr
LEFT JOIN area_commitment_attribute a ON a.vnr = f.vnr
GROUP BY v.vnr
ORDER BY v.vnr;
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, p.weight, p.kmw, ROUND(p.kmw * (4.54 + 0.022 * p.kmw), 0) AS oe, p.qualid, p.hkid, p.kgnr,
GROUP_CONCAT(DISTINCT a.attrid) as attributes, GROUP_CONCAT(DISTINCT 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 delivery_part_attribute a ON (a.year, a.did, a.dpnr) = (p.year, p.did, p.dpnr)
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;
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, attributes,
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, attributes
ORDER BY year, LENGTH(attributes) DESC, attributes;
CREATE VIEW v_stat_sort_attr AS
SELECT year, sortid, attributes,
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, attributes
ORDER BY year, sortid, LENGTH(attributes) DESC, attributes;