CREATE TABLE season ( year INTEGER NOT NULL CHECK (year >= 1000 AND year <= 9999), currency TEXT NOT NULL, precision INTEGER NOT NULL DEFAULT 4, max_kg_per_ha INTEGER NOT NULL DEFAULT 10000, vat_normal REAL NOT NULL DEFAULT 0.10, vat_flatrate REAL NOT NULL DEFAULT 0.13, min_kg_per_bs INTEGER NOT NULL, max_kg_per_bs INTEGER NOT NULL, penalty_per_kg INTEGER, penalty_amount INTEGER, penalty_none INTEGER, bs_value INTEGER, 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])$'), calc_mode INTEGER NOT NULL DEFAULT 0, CONSTRAINT pk_season PRIMARY KEY (year), CONSTRAINT fk_season_currency FOREIGN KEY (currency) REFERENCES currency (code) ON UPDATE CASCADE ON DELETE RESTRICT ) STRICT; CREATE TABLE modifier ( year INTEGER NOT NULL, modid TEXT NOT NULL CHECK (modid REGEXP '^[A-Z0-9]+$'), ordering INTEGER NOT NULL, name TEXT NOT NULL, abs INTEGER, rel REAL, 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, modid), CONSTRAINT fk_modifier_season FOREIGN KEY (year) REFERENCES season (year) ON UPDATE CASCADE ON DELETE CASCADE, CONSTRAINT c_modifier CHECK ((abs IS NOT NULL AND rel IS NULL) OR (abs IS NULL AND rel IS NOT NULL)) ) 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 CHECK (time REGEXP '^([01][0-9]|2[0-3]):[0-5][0-9]:([0-5][0-9]|60)$') 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, comment TEXT DEFAULT NULL, ctime INTEGER NOT NULL DEFAULT (UNIXEPOCH()), mtime INTEGER NOT NULL DEFAULT (UNIXEPOCH()), 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, sortid TEXT NOT NULL, attrid TEXT, weight INTEGER NOT NULL, kmw REAL NOT NULL, qualid TEXT NOT NULL, hkid TEXT NOT NULL, kgnr INTEGER DEFAULT NULL, rdnr INTEGER DEFAULT NULL, gerebelt INTEGER NOT NULL CHECK (gerebelt IN (TRUE, FALSE)), manual_weighing INTEGER NOT NULL CHECK (manual_weighing IN (TRUE, FALSE)), spl_check INTEGER NOT NULL CHECK (spl_check IN (TRUE, FALSE)) DEFAULT FALSE, hand_picked INTEGER CHECK (hand_picked IN (TRUE, FALSE)) DEFAULT NULL, lesewagen INTEGER CHECK (lesewagen IN (TRUE, FALSE)) DEFAULT NULL, gebunden INTEGER CHECK (gebunden IN (TRUE, FALSE)) DEFAULT NULL, temperature REAL DEFAULT NULL, acid REAL DEFAULT NULL, scale_id TEXT, weighing_id TEXT, weighing_reason TEXT CHECK (NOT (manual_weighing = FALSE AND weighing_reason IS NOT NULL)), comment TEXT DEFAULT NULL, ctime INTEGER NOT NULL DEFAULT (UNIXEPOCH()), mtime INTEGER NOT NULL DEFAULT (UNIXEPOCH()), 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, 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_level FOREIGN KEY (qualid) REFERENCES wine_quality_level (qualid) ON UPDATE CASCADE ON DELETE RESTRICT, CONSTRAINT fk_delivery_part_wine_origin FOREIGN KEY (hkid) REFERENCES wine_origin (hkid) ON UPDATE CASCADE ON DELETE RESTRICT, CONSTRAINT fk_delivery_part_wb_kg FOREIGN KEY (kgnr) REFERENCES wb_kg (kgnr) ON UPDATE CASCADE ON DELETE SET NULL, CONSTRAINT fk_delivery_part_wb_rd FOREIGN KEY (kgnr, rdnr) REFERENCES wb_rd (kgnr, rdnr) ON UPDATE CASCADE ON DELETE SET NULL ) STRICT; CREATE TRIGGER t_delivery_part_i BEFORE INSERT ON delivery_part FOR EACH ROW WHEN NEW.kgnr IS NOT NULL BEGIN SELECT RAISE(ABORT, 'Invalid kgnr and hkid combination') WHERE 0 = ( SELECT COUNT(*) FROM wb_kg wk JOIN AT_kg k ON wk.kgnr = k.kgnr JOIN wb_gem wg ON wg.gkz = k.gkz LEFT JOIN wine_origin wo1 ON wg.hkid = wo1.hkid LEFT JOIN wine_origin wo2 ON wo1.parent_hkid = wo2.hkid LEFT JOIN wine_origin wo3 ON wo2.parent_hkid = wo3.hkid LEFT JOIN wine_origin wo4 ON wo3.parent_hkid = wo4.hkid WHERE wk.kgnr = NEW.kgnr AND NEW.hkid IN (wo1.hkid, wo2.hkid, wo3.hkid, wo4.hkid)); END; CREATE TRIGGER t_delivery_part_u BEFORE UPDATE ON delivery_part FOR EACH ROW WHEN NEW.kgnr IS NOT NULL BEGIN SELECT RAISE(ABORT, 'Invalid kgnr and hkid combination') WHERE 0 = ( SELECT COUNT(*) FROM wb_kg wk JOIN AT_kg k ON wk.kgnr = k.kgnr JOIN wb_gem wg ON wg.gkz = k.gkz LEFT JOIN wine_origin wo1 ON wg.hkid = wo1.hkid LEFT JOIN wine_origin wo2 ON wo1.parent_hkid = wo2.hkid LEFT JOIN wine_origin wo3 ON wo2.parent_hkid = wo3.hkid LEFT JOIN wine_origin wo4 ON wo3.parent_hkid = wo4.hkid WHERE wk.kgnr = NEW.kgnr AND NEW.hkid IN (wo1.hkid, wo2.hkid, wo3.hkid, wo4.hkid)); END; 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, modid) REFERENCES modifier (year, modid) ON UPDATE CASCADE ON DELETE RESTRICT ) STRICT;