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;