PRAGMA foreign_keys = ON; CREATE TABLE meta ( version INTEGER NOT NULL DEFAULT 1 ); CREATE TABLE country ( alpha2 TEXT NOT NULL CHECK (alpha2 REGEXP '[A-Z]{2}'), alpha3 TEXT NOT NULL CHECK (alpha3 REGEXP '[A-Z]{3}'), num INTEGER NOT NULL CHECK (num >= 0), name TEXT NOT NULL, is_visible INTEGER NOT NULL CHECK (is_visible = TRUE OR is_visible = FALSE) DEFAULT TRUE, CONSTRAINT pk_country PRIMARY KEY (alpha2), CONSTRAINT sk_country_alpha3 UNIQUE (alpha3), CONSTRAINT sk_country_numeric UNIQUE (num), 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 TEXT NOT NULL, id TEXT NOT NULL, CONSTRAINT pk_postal_dest PRIMARY KEY (country, id), CONSTRAINT fk_postal_dest_country FOREIGN KEY (country) REFERENCES country (alpha2) ON UPDATE CASCADE ON DELETE RESTRICT ) STRICT; CREATE TABLE wine_variety ( code TEXT NOT NULL CHECK (code 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 (code) ) STRICT; CREATE TABLE AT_bundesland ( id INTEGER NOT NULL CHECK (id >= 0), short1 TEXT NOT NULL, short2 TEXT, name TEXT NOT NULL, CONSTRAINT pk_AT_bundesland PRIMARY KEY (id), 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), land_id 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 (land_id) REFERENCES AT_bundesland (id) 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), okz INTEGER NOT NULL, country TEXT NOT NULL GENERATED ALWAYS AS ('AT') VIRTUAL, id TEXT NOT NULL GENERATED ALWAYS AS (plz * 100000 + okz) STORED, dest TEXT NOT NULL, CONSTRAINT pk_AT_plz PRIMARY KEY (plz, okz), CONSTRAINT sk_AT_plz_id UNIQUE (id), CONSTRAINT fk_AT_plz_AT_ort FOREIGN KEY (okz) REFERENCES AT_ort (okz) ON UPDATE CASCADE ON DELETE RESTRICT, CONSTRAINT fk_AT_plz_postal_dest FOREIGN KEY (country, id) REFERENCES postal_dest (country, id) ON UPDATE CASCADE ON DELETE CASCADE ) STRICT; 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); 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); 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); END; CREATE TABLE wine_origin ( code TEXT NOT NULL CHECK (code REGEXP '[A-Z]{4}'), parent_code TEXT, name TEXT NOT NULL, land_id INTEGER, CONSTRAINT pk_wine_origin PRIMARY KEY (code), CONSTRAINT sk_wine_origin_name UNIQUE (name), CONSTRAINT fk_wine_origin_wine_origin FOREIGN KEY (parent_code) REFERENCES wine_origin (code) ON UPDATE CASCADE ON DELETE RESTRICT, CONSTRAINT fk_wine_origin_AT_bundesland FOREIGN KEY (land_id) REFERENCES AT_bundesland (id) ON UPDATE CASCADE ON DELETE RESTRICT ) STRICT; -- Großlage CREATE TABLE wb_gl ( id INTEGER NOT NULL, name TEXT NOT NULL, CONSTRAINT pk_wb_gl PRIMARY KEY (id) ) STRICT; -- Weinbaugemeinde CREATE TABLE wb_gem ( gkz INTEGER NOT NULL, origin 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 (origin) REFERENCES wine_origin (code) ON UPDATE CASCADE ON DELETE RESTRICT ) STRICT; -- Weinbaukatastralgemeinde CREATE TABLE wb_kg ( kgnr INTEGER NOT NULL, gl_id 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 (gl_id) REFERENCES wb_gl (id) ON UPDATE CASCADE ON DELETE RESTRICT ) STRICT; -- Ried CREATE TABLE wb_rd ( kgnr INTEGER NOT NULL, rdid INTEGER NOT NULL, name TEXT NOT NULL, CONSTRAINT pk_wb_rd PRIMARY KEY (kgnr, rdid), 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, CONSTRAINT pk_branch PRIMARY KEY (zwstid) ); 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, year_of_birth INTEGER CHECK (year_of_birth >= 1000 AND year_of_birth <= 9999) DEFAULT NULL, entry_date TEXT NOT NULL 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, betriebs_nr INTEGER DEFAULT NULL, uid TEXT CHECK (uid REGEXP '[A-Z]{2}[A-Z0-9]{2,12}') DEFAULT NULL, voll_lieferant INTEGER NOT NULL CHECK (voll_lieferant IN (0, 1)) DEFAULT 0, buchführend INTEGER NOT NULL CHECK (buchführend IN (0, 1)) DEFAULT 0, active INTEGER NOT NULL CHECK (active IN (0, 1)) DEFAULT 1, 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 TEXT NOT NULL, postal_dest TEXT NOT NULL, address TEXT, email TEXT CHECK (email REGEXP '[^@]+@([a-z0-9_\x2D]+\.)[a-z]{2,}') DEFAULT NULL, phone_landline TEXT CHECK (phone_landline REGEXP '\+[0-9]+') DEFAULT NULL, phone_mobile TEXT CHECK (phone_landline REGEXP '\+[0-9]+') DEFAULT NULL, comment TEXT DEFAULT NULL, default_kgnr INTEGER NOT NULL, default_zwstid TEXT NOT NULL, CONSTRAINT pk_member PRIMARY KEY (mgnr), 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 RESTRICT, CONSTRAINT fk_member_branch FOREIGN KEY (default_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 TEXT NOT NULL, postal_dest TEXT NOT NULL, address TEXT NOT NULL, CONSTRAINT pk_member_billing_address PRIMARY KEY (mgnr), CONSTRAINT fk_member_billing_address_postal_dest FOREIGN KEY (country, postal_dest) references postal_dest (country, id) ON UPDATE CASCADE ON DELETE RESTRICT ) STRICT;