Update database schema
This commit is contained in:
@ -359,7 +359,6 @@ CREATE TABLE area_commitment (
|
||||
area INTEGER NOT NULL,
|
||||
|
||||
sortid TEXT NOT NULL,
|
||||
attrid TEXT,
|
||||
cultid TEXT NOT NULL,
|
||||
|
||||
CONSTRAINT pk_area_commitment PRIMARY KEY (vnr, kgnr, gstnr),
|
||||
@ -369,9 +368,6 @@ CREATE TABLE area_commitment (
|
||||
CONSTRAINT fk_area_commitment_wine_variety FOREIGN KEY (sortid) REFERENCES wine_variety (sortid)
|
||||
ON UPDATE CASCADE
|
||||
ON DELETE RESTRICT,
|
||||
CONSTRAINT fk_area_commitment_wine_attribute FOREIGN KEY (attrid) REFERENCES wine_attribute (attrid)
|
||||
ON UPDATE CASCADE
|
||||
ON DELETE RESTRICT,
|
||||
CONSTRAINT fk_area_commitment_wine_cultivation FOREIGN KEY (cultid) REFERENCES wine_cultivation (cultid)
|
||||
ON UPDATE CASCADE
|
||||
ON DELETE RESTRICT,
|
||||
@ -380,6 +376,21 @@ CREATE TABLE area_commitment (
|
||||
ON DELETE RESTRICT
|
||||
) STRICT;
|
||||
|
||||
CREATE TABLE area_commitment_attribute (
|
||||
vnr INTEGER NOT NULL,
|
||||
kgnr INTEGER NOT NULL,
|
||||
gstnr TEXT NOT NULL,
|
||||
attrid TEXT NOT NULL,
|
||||
|
||||
CONSTRAINT pk_area_commitment_attribute PRIMARY KEY (vnr, kgnr, gstnr, attrid),
|
||||
CONSTRAINT fk_area_commitment_attribute_area_commitment FOREIGN KEY (vnr, kgnr, gstnr) REFERENCES area_commitment (vnr, kgnr, gstnr)
|
||||
ON UPDATE CASCADE
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT fk_area_commitment_attribute_wine_attribute FOREIGN KEY (attrid) REFERENCES wine_attribute (attrid)
|
||||
ON UPDATE CASCADE
|
||||
ON DELETE RESTRICT
|
||||
) STRICT;
|
||||
|
||||
|
||||
----------------------------------------------------------------
|
||||
|
||||
@ -400,7 +411,7 @@ CREATE TABLE season (
|
||||
|
||||
CREATE TABLE modifier (
|
||||
year INTEGER NOT NULL,
|
||||
mnr INTEGER NOT NULL,
|
||||
modid TEXT NOT NULL CHECK (modid REGEXP '^[A-Z]+$'),
|
||||
|
||||
name TEXT NOT NULL,
|
||||
abs INTEGER,
|
||||
@ -409,7 +420,7 @@ CREATE TABLE modifier (
|
||||
standard INTEGER NOT NULL CHECK (standard IN (TRUE, FALSE)),
|
||||
quick_select INTEGER NOT NULL CHECK (quick_select IN (TRUE, FALSE)),
|
||||
|
||||
CONSTRAINT pk_modifier PRIMARY KEY (year, mnr),
|
||||
CONSTRAINT pk_modifier PRIMARY KEY (year, modid),
|
||||
CONSTRAINT fk_modifier_season FOREIGN KEY (year) REFERENCES season (year)
|
||||
ON UPDATE CASCADE
|
||||
ON DELETE CASCADE,
|
||||
@ -459,8 +470,6 @@ CREATE TABLE delivery_part (
|
||||
dpnr INTEGER NOT NULL,
|
||||
|
||||
sortid TEXT NOT NULL,
|
||||
attrid TEXT DEFAULT NULL,
|
||||
|
||||
weight INTEGER NOT NULL,
|
||||
kmw REAL NOT NULL,
|
||||
qualid TEXT NOT NULL,
|
||||
@ -474,7 +483,7 @@ CREATE TABLE delivery_part (
|
||||
spl_check INTEGER NOT NULL CHECK (spl_check IN (TRUE, FALSE)) DEFAULT FALSE,
|
||||
|
||||
hand_picked INTEGER CHECK (hand_picked IN (TRUE, FALSE)) DEFAULT NULL,
|
||||
lesemaschine INTEGER CHECK (lesemaschine IN (True, FALSE)) DEFAULT NULL,
|
||||
lesewagen INTEGER CHECK (lesewagen IN (True, FALSE)) DEFAULT NULL,
|
||||
|
||||
temperature REAL DEFAULT NULL,
|
||||
acid REAL DEFAULT NULL,
|
||||
@ -491,9 +500,6 @@ CREATE TABLE delivery_part (
|
||||
CONSTRAINT fk_delivery_part_wine_variety FOREIGN KEY (sortid) REFERENCES wine_variety (sortid)
|
||||
ON UPDATE CASCADE
|
||||
ON DELETE RESTRICT,
|
||||
CONSTRAINT fk_delivery_part_wine_attribute FOREIGN KEY (attrid) REFERENCES wine_attribute (attrid)
|
||||
ON UPDATE CASCADE
|
||||
ON DELETE RESTRICT,
|
||||
CONSTRAINT fk_delivery_part_wine_quality FOREIGN KEY (qualid) REFERENCES wine_quality (qualid)
|
||||
ON UPDATE CASCADE
|
||||
ON DELETE RESTRICT,
|
||||
@ -534,17 +540,32 @@ BEGIN
|
||||
) WHERE (year, did, dpnr) = (NEW.year, NEW.did, NEW.dpnr);
|
||||
END;
|
||||
|
||||
CREATE TABLE delivery_part_modifier (
|
||||
year INTEGER NOT NULL,
|
||||
did INTEGER NOT NULL,
|
||||
dpnr INTEGER NOT NULL,
|
||||
mnr INTEGER NOT NULL,
|
||||
CREATE TABLE delivery_part_attribute (
|
||||
year INTEGER NOT NULL,
|
||||
did INTEGER NOT NULL,
|
||||
dpnr INTEGER NOT NULL,
|
||||
attrid TEXT NOT NULL,
|
||||
|
||||
CONSTRAINT pk_delivery_part_modifier PRIMARY KEY (year, did, dpnr, mnr),
|
||||
CONSTRAINT pk_delivery_part_attribute PRIMARY KEY (year, did, dpnr, attrid),
|
||||
CONSTRAINT fk_delivery_part_attribute_delivery_part FOREIGN KEY (year, did, dpnr) REFERENCES delivery_part (year, did, dpnr)
|
||||
ON UPDATE CASCADE
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT fk_delivery_part_attribute_wine_attribute FOREIGN KEY (attrid) REFERENCES wine_attribute (attrid)
|
||||
ON UPDATE CASCADE
|
||||
ON DELETE RESTRICT
|
||||
) STRICT;
|
||||
|
||||
CREATE TABLE delivery_part_modifier (
|
||||
year INTEGER NOT NULL,
|
||||
did INTEGER NOT NULL,
|
||||
dpnr INTEGER NOT NULL,
|
||||
modid TEXT NOT NULL,
|
||||
|
||||
CONSTRAINT pk_delivery_part_modifier PRIMARY KEY (year, did, dpnr, modid),
|
||||
CONSTRAINT fk_delivery_part_modifier_delivery_part FOREIGN KEY (year, did, dpnr) REFERENCES delivery_part (year, did, dpnr)
|
||||
ON UPDATE CASCADE
|
||||
ON DELETE CASCADE,
|
||||
CONSTRAINT fk_delivery_part_modifier_modifier FOREIGN KEY (year, mnr) REFERENCES modifier (year, mnr)
|
||||
CONSTRAINT fk_delivery_part_modifier_modifier FOREIGN KEY (year, modid) REFERENCES modifier (year, modid)
|
||||
ON UPDATE CASCADE
|
||||
ON DELETE RESTRICT
|
||||
) STRICT;
|
||||
|
@ -4,3 +4,62 @@ SELECT plz, p.dest AS bestimmungsort, g.name AS gemeinde, g.gkz, o.name AS ort,
|
||||
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_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;
|
||||
|
Reference in New Issue
Block a user