Update db schema, Weinbaugemeinden

This commit is contained in:
2023-02-04 17:07:37 +01:00
parent 6762200c25
commit e73ac85682
6 changed files with 180 additions and 47 deletions

207
sql/v01/01.create.sql Normal file
View File

@ -0,0 +1,207 @@
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,
origin TEXT NOT NULL,
name TEXT NOT NULL,
CONSTRAINT pk_wb_gl PRIMARY KEY (id),
CONSTRAINT fk_wb_gl_wine_origin FOREIGN KEY (origin) REFERENCES wine_origin (code)
ON UPDATE CASCADE
ON DELETE RESTRICT
) 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;

13
sql/v01/02.view.sql Normal file
View File

@ -0,0 +1,13 @@
CREATE VIEW v_plz AS
SELECT plz, o.name AS ort, g.name AS gemeinde, p.name AS bestimmungsort
FROM AT_gemeinde g
JOIN AT_ort o ON o.gkz = g.gkz
JOIN AT_plz p ON p.okz = o.okz;
CREATE VIEW v_plz_wg AS
SELECT plz, o.name AS ort, g.name AS gemeinde, p.name AS bestimmungsort
FROM AT_gemeinde g
JOIN AT_ort o ON o.gkz = g.gkz
JOIN AT_plz p ON p.okz = o.okz
WHERE (g.gkz / 100) IN (308, 316, 310, 312, 321);

110
sql/v01/03.base.sql Normal file
View File

@ -0,0 +1,110 @@
INSERT INTO country VALUES
('AT', 'AUT', 40, 'Österreich', TRUE),
('DE', 'DEU', 276, 'Deutschland', FALSE),
('CZ', 'CZE', 203, 'Tschechien', FALSE),
('HU', 'HUN', 348, 'Ungarn', FALSE),
('SK', 'SVK', 703, 'Slowakei', FALSE),
('IT', 'ITA', 380, 'Italien', FALSE),
('NL', 'NLD', 528, 'Niederlande', FALSE),
('LU', 'LUX', 442, 'Luxemburg', FALSE),
('BE', 'BEL', 56, 'Belgien', FALSE),
('FR', 'FRA', 250, 'France', FALSE),
('ES', 'ESP', 724, 'Spanien', FALSE),
('PT', 'PRT', 620, 'Portugal', FALSE);
INSERT INTO currency VALUES
('EUR', 'Euro', '', 10000),
('ATS', 'Schilling', 'S', 137603),
('XXP', 'Punkte', 'Pkt.', NULL);
INSERT INTO AT_bundesland VALUES
(1, 'B', 'Bgld.', 'Burgenland'),
(2, 'K', 'Ktn.', 'Kärnten'),
(3, 'N', '', 'Niederösterreich'),
(4, 'O', '', 'Oberösterreich'),
(5, 'S', 'Sbg.', 'Salzburg'),
(6, 'St', 'Stmk.', 'Steiermark'),
(7, 'T', NULL, 'Tirol'),
(8, 'V', 'Vbg.', 'Vorarlberg'),
(9, 'W', NULL, 'Wien');
INSERT INTO wine_origin VALUES
('AUSL', NULL , 'Ausland', NULL),
('EUXX', NULL , 'Verschnitt von mehreren Weinen der EU', NULL),
('OEST', NULL , 'Österreich', NULL),
('BLXX', 'OEST', 'Bergland', NULL),
('SLXX', 'OEST', 'Steirerland', NULL),
('WLXX', 'OEST', 'Weinland', NULL),
('BLKA', 'BLXX', 'Kärnten', 2),
('BLOO', 'BLXX', 'Oberösterreich', 4),
('BLSB', 'BLXX', 'Salzburg', 5),
('BLTI', 'BLXX', 'Tirol', 7),
('BLVO', 'BLXX', 'Vorarlberg', 8),
('SLST', 'SLXX', 'Steiermark', 6),
('SLSS', 'SLST', 'Südsteiermark', NULL),
('SLVL', 'SLST', 'Vulkanland Steiermark', NULL),
('SLWS', 'SLST', 'Weststeiermark', NULL),
('WIEN', 'WLXX', 'Wien', 9),
('WLNO', 'WLXX', 'Niederösterreich', 3),
('WLBL', 'WLXX', 'Burgenland', 1),
('WLCA', 'WLNO', 'Carnuntum', NULL),
('WLKA', 'WLNO', 'Kamptal', NULL),
('WLKT', 'WLNO', 'Kremstal', NULL),
('WLTH', 'WLNO', 'Thermenregion', NULL),
('WLTT', 'WLNO', 'Traisental', NULL),
('WLWA', 'WLNO', 'Wachau', NULL),
('WLWG', 'WLNO', 'Wagram', NULL),
('WLWV', 'WLNO', 'Weinviertel', NULL),
('WLNS', 'WLBL', 'Neusiedlersee', NULL),
('WLLB', 'WLBL', 'Leithaberg', NULL),
('WLRO', 'WLBL', 'Rosalia', NULL),
('WLMB', 'WLBL', 'Mittelburgenland', NULL),
('WLEB', 'WLBL', 'Eisenberg', NULL);
INSERT INTO wine_variety VALUES
('BL', 'R', 'Blauburger', NULL),
('BB', 'R', 'Blauer Burgunder', 'Blauer Spätburgunder, Blauburgunder, Pinot Noir'),
('BP', 'R', 'Blauer Portugieser', NULL),
('BW', 'R', 'Blauer Wildbacher', NULL),
('BF', 'R', 'Blaufränkisch', 'Frankovka'),
('BM', 'W', 'Blütenmuskateller', NULL),
('BO', 'W', 'Bouvier', NULL),
('CF', 'R', 'Cabernet Franc', NULL),
('CS', 'R', 'Cabernet Sauvignon', NULL),
('CH', 'W', 'Chardonnay', 'Morillon'),
('FV', 'W', 'Frühroter Veltliner', 'Malvasier'),
('FU', 'W', 'Furmint', NULL),
('GW', 'W', 'Gemischter Satz weiß', NULL),
('GB', 'W', 'Goldburger', NULL),
('GL', 'W', 'Goldmuskateller', NULL),
('GR', 'W', 'Grauer Burgunder', 'Grauburgunder, Pinot Gris, Ruländer'),
('GV', 'W', 'Grüner Veltliner', 'Weißgipfler'),
('JU', 'W', 'Jubiläumsrebe', NULL),
('ME', 'R', 'Merlot', NULL),
('MT', 'W', 'Müller Thurgau', 'Rivaner'),
('MC', 'W', 'Muscaris', NULL),
('MO', 'W', 'Muskat Ottonel', NULL),
('MU', 'W', 'Muskateller', 'Gelber Muskateller, Roter Muskateller'),
('NB', 'W', 'Neuburger', NULL),
('RH', 'R', 'Rathay', NULL),
('RR', 'W', 'Riesling', 'Weißer Riesling, Rheinriesling, Roter Riesling'),
('RL', 'R', 'Roesler', NULL),
('RM', 'R', 'Rosenmuskateller', NULL),
('RV', 'W', 'Roter Veltliner', NULL),
('RG', 'W', 'Rotgipfler', NULL),
('SB', 'W', 'Sauvignon Blanc', NULL),
('SA', 'W', 'Scheurebe', 'Sämling 88'),
-- ('SP', '', 'Sortenverschnitt gleichgepresst', NULL),
('SR', 'R', 'Sortenverschnitt Rosé', NULL),
('SO', 'R', 'Sortenverschnitt rot', NULL),
('SW', 'W', 'Sortenverschnitt weiß', NULL),
('SG', 'W', 'Souvignier Gris', NULL),
('SL', 'R', 'St. Laurent', NULL),
('SY', 'W', 'Sylvaner', 'Grüner Sylvaner'),
('SH', 'R', 'Syrah', 'Shiraz'),
('TR', 'W', 'Traminer', 'Gewürztraminer, Roter Traminer, Gelber Traminer'),
('WB', 'W', 'Weißer Burgunder', 'Weißburgunder, Pinot Blanc, Klevner'),
('WR', 'W', 'Welschriesling', NULL),
('ZF', 'W', 'Zierfandler', 'Spätrot'),
('ZW', 'R', 'Zweigelt', 'Blauer Zweigelt, Rotburger');