From 60cf52ba035cb05c5387961fc6019b7c587defd3 Mon Sep 17 00:00:00 2001
From: Lorenz Stechauner <lorenz.stechauner@necronda.net>
Date: Mon, 13 Feb 2023 19:16:40 +0100
Subject: [PATCH] Add Lieferungen

---
 sql/v01/01.create.sql | 152 +++++++++++++++++++++++++++++++++++-------
 sql/v01/03.base.sql   |  21 ++++++
 2 files changed, 148 insertions(+), 25 deletions(-)

diff --git a/sql/v01/01.create.sql b/sql/v01/01.create.sql
index 3510774..9f58359 100644
--- a/sql/v01/01.create.sql
+++ b/sql/v01/01.create.sql
@@ -39,15 +39,6 @@ CREATE TABLE postal_dest (
         ON DELETE RESTRICT
 ) STRICT;
 
-CREATE TABLE wine_variety (
-    sortid  TEXT NOT NULL CHECK (sortid REGEXP '[A-Z]{2}'),
-    type    TEXT NOT NULL CHECK (type IN ('R', 'W')),
-    name    TEXT NOT NULL,
-    comment TEXT,
-
-    CONSTRAINT pk_wine_variety PRIMARY KEY (sortid)
-) STRICT;
-
 CREATE TABLE AT_bundesland (
     blnr   INTEGER NOT NULL CHECK (blnr >= 0),
     short1 TEXT    NOT NULL,
@@ -120,21 +111,41 @@ CREATE TABLE AT_plz (
 CREATE TRIGGER t_AT_plz_i
     AFTER INSERT ON AT_plz FOR EACH ROW
 BEGIN
-    INSERT INTO postal_dest (country, id) VALUES (new.country, new.id);
+    INSERT INTO postal_dest (country, id) VALUES (NEW.country, NEW.id);
 END;
 
 CREATE TRIGGER t_AT_plz_u
     AFTER UPDATE OF id ON AT_plz FOR EACH ROW
 BEGIN
-    UPDATE postal_dest SET country = new.country, id = new.id WHERE (country, id) = (old.country, old.id);
+    UPDATE postal_dest SET country = NEW.country, id = NEW.id WHERE (country, id) = (OLD.country, OLD.id);
 END;
 
 CREATE TRIGGER t_AT_plz_d
     AFTER DELETE ON AT_plz FOR EACH ROW
 BEGIN
-    DELETE FROM postal_dest WHERE (country, id) = (old.country, old.id);
+    DELETE FROM postal_dest WHERE (country, id) = (OLD.country, OLD.id);
 END;
 
+CREATE TABLE wine_variety (
+    sortid  TEXT NOT NULL CHECK (sortid REGEXP '[A-Z]{2}'),
+    type    TEXT NOT NULL CHECK (type IN ('R', 'W')),
+    name    TEXT NOT NULL,
+    comment TEXT,
+
+    CONSTRAINT pk_wine_variety PRIMARY KEY (sortid)
+) STRICT;
+
+CREATE TABLE wine_quality (
+    qualid       TEXT    NOT NULL CHECK (qualid REGEXP '[A-Z]{3}'),
+    origin_level INTEGER NOT NULL,
+
+    name         TEXT    NOT NULL,
+    from_kmw     INTEGER DEFAULT NULL,
+    to_kmw       INTEGER DEFAULT NULL,
+
+    CONSTRAINT pk_wine_quality PRIMARY KEY (qualid)
+) STRICT;
+
 CREATE TABLE wine_origin (
     hkid        TEXT NOT NULL CHECK (hkid REGEXP '[A-Z]{4}'),
     parent_hkid TEXT,
@@ -228,19 +239,6 @@ CREATE TABLE wine_cultivation (
     CONSTRAINT pk_wine_cultivation PRIMARY KEY (cultid)
 ) STRICT;
 
-CREATE TABLE season (
-    year       INTEGER NOT NULL CHECK (year >= 1000 AND year <= 9999),
-    currency   TEXT    NOT NULL,
-
-    start_date TEXT CHECK (start_date REGEXP '[1-9][0-9]{3}-(0[1-9]|1[012])-(0[1-9]|[12][0-9]|3[01])'),
-    end_date   TEXT CHECK (end_date   REGEXP '[1-9][0-9]{3}-(0[1-9]|1[012])-(0[1-9]|[12][0-9]|3[01])'),
-
-    CONSTRAINT pk_season PRIMARY KEY (year),
-    CONSTRAINT fk_season_currency FOREIGN KEY (currency) REFERENCES currency (code)
-        ON UPDATE CASCADE
-        ON DELETE RESTRICT
-);
-
 CREATE TABLE member (
     mgnr             INTEGER NOT NULL,
     predecessor_mgnr INTEGER          DEFAULT NULL,
@@ -354,3 +352,107 @@ CREATE TABLE area_commitment (
         ON UPDATE CASCADE
         ON DELETE RESTRICT
 ) STRICT;
+
+
+----------------------------------------------------------------
+
+
+CREATE TABLE season (
+    year       INTEGER NOT NULL CHECK (year >= 1000 AND year <= 9999),
+    currency   TEXT    NOT NULL,
+
+    start_date TEXT CHECK (start_date REGEXP '[1-9][0-9]{3}-(0[1-9]|1[012])-(0[1-9]|[12][0-9]|3[01])'),
+    end_date   TEXT CHECK (end_date   REGEXP '[1-9][0-9]{3}-(0[1-9]|1[012])-(0[1-9]|[12][0-9]|3[01])'),
+
+    CONSTRAINT pk_season PRIMARY KEY (year),
+    CONSTRAINT fk_season_currency FOREIGN KEY (currency) REFERENCES currency (code)
+        ON UPDATE CASCADE
+        ON DELETE RESTRICT
+);
+
+CREATE TABLE modifier (
+    year         INTEGER NOT NULL,
+    mnr          INTEGER NOT NULL,
+
+    name         TEXT    NOT NULL,
+    abs          INTEGER,
+    rel          INTEGER,
+
+    standard     INTEGER NOT NULL CHECK (standard IN (0, 1)),
+    quick_select INTEGER NOT NULL CHECK (quick_select IN (0, 1)),
+
+    CONSTRAINT pk_modifier PRIMARY KEY (year, mnr),
+    CONSTRAINT fk_modifier_season FOREIGN KEY (year) REFERENCES season (year)
+        ON UPDATE CASCADE
+        ON DELETE CASCADE
+) STRICT;
+
+CREATE TABLE delivery (
+    year   INTEGER NOT NULL,
+    did    INTEGER NOT NULL,
+
+    date   TEXT    NOT NULL CHECK (date LIKE year || '-%' AND date REGEXP '[1-9][0-9]{3}-(0[1-9]|1[012])-(0[1-9]|[12][0-9]|3[01])') DEFAULT CURRENT_DATE,
+    time   TEXT    NOT NULL CHECK (time REGEXP '([01][0-9]|2[0-3]):[0-5][0-9]:[0-5][0-9]')                                          DEFAULT CURRENT_TIME,
+    zwstid TEXT    NOT NULL,
+    lnr    INTEGER NOT NULL CHECK (lnr >= 1 AND lnr <= 999),
+    lsnr   TEXT    NOT NULL DEFAULT 'UNSET',
+
+    mgnr   INTEGER NOT NULL,
+
+    CONSTRAINT pk_delivery PRIMARY KEY (year, did),
+    CONSTRAINT sk_delivery_1 UNIQUE (date, zwstid, lnr),
+    CONSTRAINT sk_delivery_2 UNIQUE (lsnr),
+    CONSTRAINT fk_delivery_season FOREIGN KEY (year) REFERENCES season (year)
+        ON UPDATE RESTRICT
+        ON DELETE CASCADE,
+    CONSTRAINT fk_delivery_branch FOREIGN KEY (zwstid) REFERENCES branch (zwstid)
+        ON UPDATE RESTRICT
+        ON DELETE RESTRICT,
+    CONSTRAINT fk_delivery_member FOREIGN KEY (mgnr) REFERENCES member (mgnr)
+        ON UPDATE CASCADE
+        ON DELETE RESTRICT
+) STRICT;
+
+CREATE TRIGGER t_delivery_i
+    AFTER INSERT ON delivery FOR EACH ROW
+WHEN NEW.lsnr = 'UNSET'
+BEGIN
+    UPDATE delivery
+    SET lsnr = format('%04s%02s%02s%1s%03i', substr(NEW.date, 1, 4), substr(NEW.date, 6, 2), substr(NEW.date, 9, 2), zwstid, lnr)
+    WHERE (year, did) = (NEW.year, NEW.did);
+END;
+
+CREATE TABLE delivery_part (
+    year   INTEGER NOT NULL,
+    did    INTEGER NOT NULL,
+    dpnr   INTEGER NOT NULL,
+
+    weight INTEGER NOT NULL,
+    c_kmw  INTEGER NOT NULL,
+
+    gerebelt INTEGER NOT NULL,
+    handwiegung INTEGER NOT NULL,
+    spätleseüberprüfung INTEGER NOT NULL,
+
+    comment TEXT DEFAULT NULL,
+
+    CONSTRAINT pk_delivery_part PRIMARY KEY (year, did, dpnr),
+    CONSTRAINT fk_delivery_part_delivery FOREIGN KEY (year, did) REFERENCES delivery (year, did)
+        ON UPDATE CASCADE
+        ON DELETE CASCADE
+) STRICT;
+
+CREATE TABLE delivery_part_modifier (
+    year INTEGER NOT NULL,
+    did  INTEGER NOT NULL,
+    dpnr INTEGER NOT NULL,
+    mnr  INTEGER NOT NULL,
+
+    CONSTRAINT pk_delivery_part_modifier PRIMARY KEY (year, did, dpnr, mnr),
+    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)
+        ON UPDATE CASCADE
+        ON DELETE RESTRICT
+) STRICT;
diff --git a/sql/v01/03.base.sql b/sql/v01/03.base.sql
index ca58654..74c8b08 100644
--- a/sql/v01/03.base.sql
+++ b/sql/v01/03.base.sql
@@ -29,6 +29,27 @@ INSERT INTO AT_bundesland VALUES
 (8, 'V',  'Vbg.',  'Vorarlberg'),
 (9, 'W',   NULL,   'Wien');
 
+INSERT INTO wine_quality VALUES
+('WEI', 0, 'Wein',         NULL, NULL),
+('RSW', 0, 'Rebsortenwein', 115, 140),
+('LDW', 1, 'Landwein',      140, 150),
+('QUW', 3, 'Qualitätswein', 150, 170),
+('KAB', 3, 'Kabinett',      170, NULL),
+('SPL', 3, 'Spätlese',     NULL, NULL);
+
+--INSERT INTO wine_quality (qualid, name)
+--('AUL', 'Auslese'),
+--('BAL', 'Beerenauslese'),
+--('DAC', 'Districtus Austriae Controllatus'),
+--('EIW', 'Eiswein'),
+--('INW', 'Industriewein'),
+--('RAB', 'Ruster Ausbruch'),
+--('SOE', 'Sonstige Erzeugnisse'),
+--('STW', 'Strohwein'),
+--('STU', 'Sturm für Qualitätsstufe'),
+--('TGT', 'Teilweise gegorener Traubenmost'),
+--('TBA', 'Trockenbeerenauslese');
+
 INSERT INTO wine_origin VALUES
 ('AUSL',  NULL , 'Ausland', NULL),
 ('EUXX',  NULL , 'Verschnitt von mehreren Weinen der EU', NULL),