Files
elwig-misc/sql/v01/10.create.sql

716 lines
26 KiB
SQL

PRAGMA foreign_keys = ON;
CREATE TABLE meta (
name TEXT NOT NULL CHECK (name REGEXP '^[a-z_]+$'),
value TEXT NOT NULL,
CONSTRAINT pk_meta PRIMARY KEY (name)
) STRICT;
INSERT INTO meta (name, value)
VALUES ('schema_version', '1');
CREATE TABLE client_parameter (
param TEXT NOT NULL CHECK (param REGEXP '^[A-Z_]+$'),
value TEXT,
CONSTRAINT pk_parameter PRIMARY KEY (param)
) STRICT;
CREATE TABLE country (
num INTEGER NOT NULL CHECK (num >= 0),
alpha2 TEXT NOT NULL CHECK (alpha2 REGEXP '^[A-Z]{2}$'),
alpha3 TEXT NOT NULL CHECK (alpha3 REGEXP '^[A-Z]{3}$'),
name TEXT NOT NULL,
is_visible INTEGER NOT NULL CHECK (is_visible IN (TRUE, FALSE)) DEFAULT TRUE,
CONSTRAINT pk_country PRIMARY KEY (num),
CONSTRAINT sk_country_alpha2 UNIQUE (alpha2),
CONSTRAINT sk_country_alpha3 UNIQUE (alpha3),
CONSTRAINT sk_country_name UNIQUE (name)
) STRICT;
CREATE TABLE currency (
code TEXT NOT NULL CHECK (code REGEXP '^[A-Z]{3}$'),
name TEXT NOT NULL,
symbol TEXT,
one_euro INTEGER,
CONSTRAINT pk_currency PRIMARY KEY (code)
) STRICT;
CREATE TABLE postal_dest (
country INTEGER NOT NULL,
id TEXT NOT NULL,
CONSTRAINT pk_postal_dest PRIMARY KEY (country, id),
CONSTRAINT fk_postal_dest_country FOREIGN KEY (country) REFERENCES country (num)
ON UPDATE CASCADE
ON DELETE RESTRICT
) STRICT;
CREATE TABLE AT_bundesland (
blnr INTEGER NOT NULL CHECK (blnr >= 0),
short1 TEXT NOT NULL,
short2 TEXT,
name TEXT NOT NULL,
CONSTRAINT pk_AT_bundesland PRIMARY KEY (blnr),
CONSTRAINT sk_AT_bundesland_short1 UNIQUE (short1),
CONSTRAINT sk_AT_bundesland_short2 UNIQUE (short2),
CONSTRAINT sk_AT_bundesland_name UNIQUE (name)
) STRICT;
CREATE TABLE AT_gem (
gkz INTEGER NOT NULL CHECK (gkz >= 10000 AND gkz <= 99999),
blnr INTEGER NOT NULL GENERATED ALWAYS AS (gkz / 10000) VIRTUAL,
name TEXT NOT NULL,
CONSTRAINT pk_AT_gem PRIMARY KEY (gkz),
CONSTRAINT fk_AT_gem_AT_bundesland FOREIGN KEY (blnr) REFERENCES AT_bundesland (blnr)
ON UPDATE CASCADE
ON DELETE RESTRICT
) STRICT;
CREATE TABLE AT_kg (
kgnr INTEGER NOT NULL CHECK (kgnr > 0 AND kgnr < 100000),
gkz INTEGER NOT NULL,
name TEXT NOT NULL,
CONSTRAINT pk_AT_kg PRIMARY KEY (kgnr),
CONSTRAINT fk_AT_kg_AT_gem FOREIGN KEY (gkz) REFERENCES AT_gem (gkz)
ON UPDATE CASCADE
ON DELETE RESTRICT
) STRICT;
CREATE TABLE AT_ort (
okz INTEGER NOT NULL CHECK (okz > 0 AND okz < 100000),
gkz INTEGER NOT NULL,
kgnr INTEGER,
name TEXT NOT NULL,
CONSTRAINT pk_AT_ort PRIMARY KEY (okz),
CONSTRAINT fk_AT_ort_AT_gem FOREIGN KEY (gkz) REFERENCES AT_gem (gkz)
ON UPDATE CASCADE
ON DELETE RESTRICT,
CONSTRAINT fk_AT_ort_AT_kg FOREIGN KEY (kgnr) REFERENCES AT_kg (kgnr)
ON UPDATE CASCADE
ON DELETE RESTRICT
) STRICT;
CREATE TABLE AT_plz (
plz INTEGER NOT NULL CHECK (plz >= 1000 AND plz <= 9999),
ort TEXT NOT NULL,
blnr INTEGER NOT NULL,
type TEXT NOT NULL,
internal INTEGER NOT NULL CHECK (internal IN (TRUE, FALSE)),
addressable INTEGER NOT NULL CHECK (addressable IN (TRUE, FALSE)),
po_box INTEGER NOT NULL CHECK (po_box IN (TRUE, FALSE)),
CONSTRAINT pk_AT_plz PRIMARY KEY (plz),
CONSTRAINT fk_AT_plz_AT_bundesland FOREIGN KEY (blnr) REFERENCES AT_bundesland (blnr)
ON UPDATE CASCADE
ON DELETE RESTRICT
) STRICT;
CREATE TABLE AT_plz_dest (
plz INTEGER NOT NULL CHECK (plz >= 1000 AND plz <= 9999),
okz INTEGER NOT NULL,
country INTEGER NOT NULL GENERATED ALWAYS AS (40) VIRTUAL,
id TEXT NOT NULL GENERATED ALWAYS AS (plz * 100000 + okz) STORED,
dest TEXT NOT NULL,
CONSTRAINT pk_AT_plz_dest PRIMARY KEY (plz, okz),
CONSTRAINT sk_AT_plz_dest_id UNIQUE (id),
CONSTRAINT fk_AT_plz_dest_AT_ort FOREIGN KEY (okz) REFERENCES AT_ort (okz)
ON UPDATE CASCADE
ON DELETE RESTRICT,
CONSTRAINT fk_AT_plz_dest_postal_dest FOREIGN KEY (country, id) REFERENCES postal_dest (country, id)
ON UPDATE CASCADE
ON DELETE CASCADE
) STRICT;
CREATE TRIGGER t_AT_plz_dest_i
AFTER INSERT ON AT_plz_dest FOR EACH ROW
BEGIN
INSERT INTO postal_dest (country, id) VALUES (NEW.country, NEW.id);
END;
CREATE TRIGGER t_AT_plz_dest_u
AFTER UPDATE OF id ON AT_plz_dest FOR EACH ROW
BEGIN
UPDATE postal_dest SET country = NEW.country, id = NEW.id WHERE (country, id) = (OLD.country, OLD.id);
END;
CREATE TRIGGER t_AT_plz_dest_d
AFTER DELETE ON AT_plz_dest FOR EACH ROW
BEGIN
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_level (
qualid TEXT NOT NULL CHECK (qualid REGEXP '^[A-Z]{3}$'),
origin_level INTEGER NOT NULL,
predicate INTEGER NOT NULL CHECK(predicate IN (TRUE, FALSE)),
min_kmw REAL DEFAULT NULL,
name TEXT NOT NULL,
CONSTRAINT pk_wine_quality_level PRIMARY KEY (qualid)
) STRICT;
CREATE TABLE wine_origin (
hkid TEXT NOT NULL CHECK (hkid REGEXP '^[A-Z]{4}$'),
parent_hkid TEXT,
name TEXT NOT NULL,
blnr INTEGER,
CONSTRAINT pk_wine_origin PRIMARY KEY (hkid),
CONSTRAINT sk_wine_origin_name UNIQUE (name),
CONSTRAINT fk_wine_origin_wine_origin FOREIGN KEY (parent_hkid) REFERENCES wine_origin (hkid)
ON UPDATE CASCADE
ON DELETE RESTRICT,
CONSTRAINT fk_wine_origin_AT_bundesland FOREIGN KEY (blnr) REFERENCES AT_bundesland (blnr)
ON UPDATE CASCADE
ON DELETE RESTRICT
) STRICT;
-- Großlage
CREATE TABLE wb_gl (
glnr INTEGER NOT NULL,
name TEXT NOT NULL,
CONSTRAINT pk_wb_gl PRIMARY KEY (glnr)
) STRICT;
-- Weinbaugemeinde
CREATE TABLE wb_gem (
gkz INTEGER NOT NULL,
hkid TEXT NOT NULL,
CONSTRAINT pk_wb_gem PRIMARY KEY (gkz),
CONSTRAINT fk_wb_gem_AT_gem FOREIGN KEY (gkz) REFERENCES AT_gem (gkz)
ON UPDATE CASCADE
ON DELETE RESTRICT,
CONSTRAINT fk_wb_gem_wine_origin FOREIGN KEY (hkid) REFERENCES wine_origin (hkid)
ON UPDATE CASCADE
ON DELETE RESTRICT
) STRICT;
-- Weinbaukatastralgemeinde
CREATE TABLE wb_kg (
kgnr INTEGER NOT NULL,
glnr INTEGER,
CONSTRAINT pk_wb_kg PRIMARY KEY (kgnr),
CONSTRAINT fk_wb_kg_AT_kg FOREIGN KEY (kgnr) REFERENCES AT_kg (kgnr)
ON UPDATE CASCADE
ON DELETE RESTRICT,
CONSTRAINT fk_wb_gem_wb_gl FOREIGN KEY (glnr) REFERENCES wb_gl (glnr)
ON UPDATE CASCADE
ON DELETE RESTRICT
) STRICT;
-- Ried
CREATE TABLE wb_rd (
kgnr INTEGER NOT NULL,
rdnr INTEGER NOT NULL,
name TEXT NOT NULL,
CONSTRAINT pk_wb_rd PRIMARY KEY (kgnr, rdnr),
CONSTRAINT fk_wb_rd_wb_kg FOREIGN KEY (kgnr) REFERENCES wb_kg (kgnr)
ON UPDATE CASCADE
ON DELETE RESTRICT
) STRICT;
----------------------------------------------------------------
CREATE TABLE branch (
zwstid TEXT NOT NULL CHECK (zwstid REGEXP '^[A-Z]$'),
name TEXT NOT NULL,
country INTEGER DEFAULT NULL,
postal_dest TEXT DEFAULT NULL,
address TEXT DEFAULT NULL,
phone_nr TEXT DEFAULT NULL CHECK (phone_nr REGEXP '^\+[0-9]{1,3}( [0-9]+)+(-[0-9]+)?$'),
fax_nr TEXT DEFAULT NULL CHECK (fax_nr REGEXP '^\+[0-9]{1,3}( [0-9]+)+(-[0-9]+)?$'),
mobile_nr TEXT DEFAULT NULL CHECK (mobile_nr REGEXP '^\+[0-9]{1,3}( [0-9]+)+(-[0-9]+)?$'),
CONSTRAINT pk_branch PRIMARY KEY (zwstid),
CONSTRAINT fk_branch_postal_dest FOREIGN KEY (country, postal_dest) REFERENCES postal_dest (country, id)
ON UPDATE CASCADE
ON DELETE RESTRICT
) STRICT;
CREATE TABLE wine_attribute (
attrid TEXT NOT NULL CHECK (attrid REGEXP '^[A-Z]+$'),
name TEXT NOT NULL,
max_kg_per_ha INTEGER,
active INTEGER NOT NULL CHECK (active IN (TRUE, FALSE)) DEFAULT TRUE,
CONSTRAINT pk_wine_attribute PRIMARY KEY (attrid)
) STRICT;
CREATE TABLE wine_cultivation (
cultid TEXT NOT NULL CHECK (cultid REGEXP '^[A-Z]+$'),
name TEXT NOT NULL,
CONSTRAINT pk_wine_cultivation PRIMARY KEY (cultid)
) STRICT;
CREATE TABLE member (
mgnr INTEGER NOT NULL,
predecessor_mgnr INTEGER DEFAULT NULL,
prefix TEXT DEFAULT NULL,
given_name TEXT NOT NULL,
middle_names TEXT DEFAULT NULL,
family_name TEXT NOT NULL,
suffix TEXT DEFAULT NULL,
birthday TEXT CHECK (birthday REGEXP '^[1-9][0-9]{3}(-(0[1-9]|1[012])(-(0[1-9]|[12][0-9]|3[01]))?)?$') DEFAULT NULL,
entry_date TEXT CHECK (entry_date REGEXP '^[1-9][0-9]{3}-(0[1-9]|1[012])-(0[1-9]|[12][0-9]|3[01])$') DEFAULT CURRENT_DATE,
exit_date TEXT CHECK (exit_date REGEXP '^[1-9][0-9]{3}-(0[1-9]|1[012])-(0[1-9]|[12][0-9]|3[01])$') DEFAULT NULL,
business_shares INTEGER NOT NULL DEFAULT 0,
accounting_nr TEXT DEFAULT NULL,
zwstid TEXT CHECK (NOT active OR zwstid IS NOT NULL),
lfbis_nr TEXT CHECK (lfbis_nr REGEXP '^[0-9]{7}$') DEFAULT NULL,
ustid_nr TEXT CHECK (ustid_nr REGEXP '^[A-Z]{2}[A-Z0-9]{2,12}$') DEFAULT NULL,
volllieferant INTEGER NOT NULL CHECK (volllieferant IN (TRUE, FALSE)) DEFAULT FALSE,
buchführend INTEGER NOT NULL CHECK (buchführend IN (TRUE, FALSE)) DEFAULT FALSE,
funktionär INTEGER NOT NULL CHECK (funktionär IN (TRUE, FALSE)) DEFAULT FALSE,
active INTEGER NOT NULL CHECK (active IN (TRUE, FALSE)) DEFAULT TRUE,
deceased INTEGER NOT NULL CHECK (deceased IN (TRUE, FALSE)) DEFAULT FALSE,
iban TEXT CHECK (iban REGEXP '^[A-Z]{2}[0-9]{2}[A-Z0-9]{8,30}$') DEFAULT NULL,
bic TEXT CHECK (bic REGEXP '^[A-Z0-9]{4}[A-Z]{2}[A-Z0-9]{2}([A-Z0-9]{3})?$') DEFAULT NULL,
country INTEGER NOT NULL,
postal_dest TEXT NOT NULL,
address TEXT NOT NULL,
email TEXT CHECK (email REGEXP '^[^@ ]+@([a-z0-9_\x2Däöüß]+\.)+[a-z]{2,}$') DEFAULT NULL,
default_kgnr INTEGER,
contact_postal INTEGER NOT NULL CHECK (contact_postal IN (TRUE, FALSE)) DEFAULT TRUE,
contact_email INTEGER NOT NULL CHECK (contact_email IN (TRUE, FALSE)) DEFAULT FALSE,
comment TEXT DEFAULT NULL,
ctime INTEGER NOT NULL DEFAULT (UNIXEPOCH()),
mtime INTEGER NOT NULL DEFAULT (UNIXEPOCH()),
CONSTRAINT pk_member PRIMARY KEY (mgnr),
CONSTRAINT fk_member_member FOREIGN KEY (predecessor_mgnr) REFERENCES member (mgnr)
ON UPDATE CASCADE
ON DELETE SET NULL,
CONSTRAINT fk_member_postal_dest FOREIGN KEY (country, postal_dest) REFERENCES postal_dest (country, id)
ON UPDATE CASCADE
ON DELETE RESTRICT,
CONSTRAINT fk_member_wb_kg FOREIGN KEY (default_kgnr) REFERENCES wb_kg (kgnr)
ON UPDATE CASCADE
ON DELETE SET NULL,
CONSTRAINT fk_member_branch FOREIGN KEY (zwstid) REFERENCES branch (zwstid)
ON UPDATE CASCADE
ON DELETE RESTRICT
) STRICT;
CREATE TABLE member_billing_address (
mgnr INTEGER NOT NULL,
name TEXT NOT NULL,
country INTEGER NOT NULL,
postal_dest TEXT NOT NULL,
address TEXT NOT NULL,
CONSTRAINT pk_member_billing_address PRIMARY KEY (mgnr),
CONSTRAINT fk_member_billing_address_member FOREIGN KEY (mgnr) REFERENCES member (mgnr)
ON UPDATE CASCADE
ON DELETE CASCADE,
CONSTRAINT fk_member_billing_address_postal_dest FOREIGN KEY (country, postal_dest) REFERENCES postal_dest (country, id)
ON UPDATE CASCADE
ON DELETE RESTRICT
) STRICT;
CREATE TABLE member_telephone_number (
mgnr INTEGER NOT NULL,
nr INTEGER NOT NULL,
type TEXT NOT NULL CHECK (type REGEXP '^[a-z_]+$'),
number TEXT NOT NULL CHECK (number REGEXP '^\+[0-9]{1,3}( [0-9]+)+(-[0-9]+)?$' AND LENGTH(REPLACE(REPLACE(REPLACE(number, '+', ''), ' ', ''), '-', '')) <= 15),
comment TEXT DEFAULT NULL,
CONSTRAINT pk_member_telephone_number PRIMARY KEY (mgnr, nr),
CONSTRAINT fk_member_telephone_number_member FOREIGN KEY (mgnr) REFERENCES member (mgnr)
ON UPDATE CASCADE
ON DELETE CASCADE
) STRICT;
CREATE TABLE area_commitment (
fbnr INTEGER NOT NULL,
mgnr INTEGER NOT NULL,
sortid TEXT NOT NULL,
cultid TEXT NOT NULL,
area INTEGER NOT NULL,
kgnr INTEGER NOT NULL,
gstnr TEXT NOT NULL,
rdnr INTEGER,
year_from INTEGER CHECK (year_from >= 1000 AND year_from <= 9999) DEFAULT NULL,
year_to INTEGER CHECK (year_to >= 1000 AND year_to <= 9999) DEFAULT NULL,
comment TEXT DEFAULT NULL,
ctime INTEGER NOT NULL DEFAULT (UNIXEPOCH()),
mtime INTEGER NOT NULL DEFAULT (UNIXEPOCH()),
CONSTRAINT pk_are_commitment PRIMARY KEY (fbnr),
CONSTRAINT fk_are_commitment_member FOREIGN KEY (mgnr) REFERENCES member (mgnr)
ON UPDATE CASCADE
ON DELETE RESTRICT,
CONSTRAINT fk_area_commitment_wine_variety FOREIGN KEY (sortid) REFERENCES wine_variety (sortid)
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,
CONSTRAINT fk_area_commitment_wb_kg FOREIGN KEY (kgnr) REFERENCES wb_kg (kgnr)
ON UPDATE CASCADE
ON DELETE RESTRICT,
CONSTRAINT fk_area_commitment_wb_rd FOREIGN KEY (kgnr, rdnr) REFERENCES wb_rd (kgnr, rdnr)
ON UPDATE CASCADE
ON DELETE RESTRICT
) STRICT;
CREATE TABLE area_commitment_attribute (
fbnr INTEGER NOT NULL,
attrid TEXT NOT NULL,
CONSTRAINT pk_area_commitment_attribute PRIMARY KEY (fbnr, attrid),
CONSTRAINT fk_area_commitment_attribute_area_commitment FOREIGN KEY (fbnr) REFERENCES area_commitment (fbnr)
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;
----------------------------------------------------------------
CREATE TABLE season (
year INTEGER NOT NULL CHECK (year >= 1000 AND year <= 9999),
currency TEXT NOT NULL,
precision INTEGER NOT NULL DEFAULT 2,
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
) 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,
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,
temperature REAL DEFAULT NULL,
acid REAL DEFAULT NULL,
scale_id TEXT,
weighing_id TEXT,
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_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_attribute (
year INTEGER NOT NULL,
did INTEGER NOT NULL,
dpnr INTEGER NOT NULL,
attrid TEXT NOT NULL,
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, modid) REFERENCES modifier (year, modid)
ON UPDATE CASCADE
ON DELETE RESTRICT
) STRICT;
CREATE TABLE payment_variant (
year INTEGER NOT NULL,
avnr INTEGER NOT NULL,
name TEXT NOT NULL,
date TEXT NOT NULL CHECK (date REGEXP '^[1-9][0-9]{3}-(0[1-9]|1[012])-(0[1-9]|[12][0-9]|3[01])$') DEFAULT CURRENT_DATE,
test_variant INTEGER NOT NULL CHECK (test_variant IN (TRUE, FALSE)),
calc_time INTEGER,
bucket_1_name TEXT DEFAULT NULL,
bucket_2_name TEXT DEFAULT NULL,
bucket_3_name TEXT DEFAULT NULL,
bucket_4_name TEXT DEFAULT NULL,
bucket_5_name TEXT DEFAULT NULL,
bucket_6_name TEXT DEFAULT NULL,
bucket_7_name TEXT DEFAULT NULL,
bucket_8_name TEXT DEFAULT NULL,
bucket_9_name TEXT DEFAULT NULL,
comment TEXT DEFAULT NULL,
data TEXT NOT NULL,
ctime INTEGER NOT NULL DEFAULT (UNIXEPOCH()),
mtime INTEGER NOT NULL DEFAULT (UNIXEPOCH()),
CONSTRAINT pk_payment PRIMARY KEY (year, avnr)
) STRICT;
CREATE TABLE payment_delivery (
year INTEGER NOT NULL,
did INTEGER NOT NULL,
dpnr INTEGER NOT NULL,
avnr INTEGER NOT NULL,
mod_abs INTEGER NOT NULL DEFAULT 0,
mod_rel REAL NOT NULL DEFAULT 0,
bucket_1 INTEGER DEFAULT NULL,
bucket_2 INTEGER DEFAULT NULL,
bucket_3 INTEGER DEFAULT NULL,
bucket_4 INTEGER DEFAULT NULL,
bucket_5 INTEGER DEFAULT NULL,
bucket_6 INTEGER DEFAULT NULL,
bucket_7 INTEGER DEFAULT NULL,
bucket_8 INTEGER DEFAULT NULL,
bucket_9 INTEGER DEFAULT NULL,
price_1 INTEGER DEFAULT NULL,
price_2 INTEGER DEFAULT NULL,
price_3 INTEGER DEFAULT NULL,
price_4 INTEGER DEFAULT NULL,
price_5 INTEGER DEFAULT NULL,
price_6 INTEGER DEFAULT NULL,
price_7 INTEGER DEFAULT NULL,
price_8 INTEGER DEFAULT NULL,
price_9 INTEGER DEFAULT NULL,
amount INTEGER NOT NULL,
CONSTRAINT pk_payment_delivery PRIMARY KEY (year, did, dpnr, avnr),
CONSTRAINT fk_payment_delivery_delivery_part FOREIGN KEY (year, did, dpnr) REFERENCES delivery_part (year, did, dpnr)
ON UPDATE CASCADE
ON DELETE CASCADE,
CONSTRAINT fk_payment_delivery_payment_variant FOREIGN KEY (year, avnr) REFERENCES payment_variant (year, avnr)
ON UPDATE CASCADE
ON DELETE CASCADE
) STRICT;
CREATE TRIGGER t_payment_delivery_i
AFTER INSERT ON payment_delivery FOR EACH ROW
BEGIN
INSERT INTO payment_member (year, avnr, mgnr, amount)
VALUES (NEW.year, NEW.avnr, (SELECT mgnr FROM delivery WHERE (year, did) = (NEW.year, NEW.did)), NEW.amount)
ON CONFLICT DO UPDATE SET amount = amount + NEW.amount;
END;
CREATE TRIGGER t_payment_delivery_u
AFTER UPDATE OF amount ON payment_delivery FOR EACH ROW
BEGIN
UPDATE payment_member
SET amount = amount - OLD.amount + NEW.amount
WHERE (year, avnr, mgnr) = (NEW.year, NEW.avnr, (SELECT mgnr FROM delivery WHERE (year, did) = (NEW.year, NEW.did)));
END;
CREATE TRIGGER t_payment_delivery_d
AFTER DELETE ON payment_delivery FOR EACH ROW
BEGIN
UPDATE payment_member
SET amount = amount - OLD.amount
WHERE (year, avnr, mgnr) = (OLD.year, OLD.avnr, (SELECT mgnr FROM delivery WHERE (year, did) = (OLD.year, OLD.did)));
END;
CREATE TABLE payment_member (
year INTEGER NOT NULL,
avnr INTEGER NOT NULL,
mgnr INTEGER NOT NULL,
amount INTEGER NOT NULL,
CONSTRAINT pk_payment_member PRIMARY KEY (year, avnr, mgnr),
CONSTRAINT fk_payment_member_payment_variant FOREIGN KEY (year, avnr) REFERENCES payment_variant (year, avnr)
ON UPDATE CASCADE
ON DELETE CASCADE,
CONSTRAINT fk_payment_member_member FOREIGN KEY (mgnr) REFERENCES member (mgnr)
ON UPDATE CASCADE
ON DELETE CASCADE
) STRICT;