Add contract, area_commitment, wine_attribute, wine_cultivation, season

This commit is contained in:
2023-02-09 11:56:46 +01:00
parent 4e12bc03f4
commit 8a50842631
2 changed files with 137 additions and 47 deletions

View File

@ -7,6 +7,18 @@ INSERT INTO wb_gl VALUES
INSERT INTO branch VALUES
('M', 'Matzen');
INSERT INTO wine_attribute VALUES
('B', 'BIO AT-BIO-302', 10000),
('HK', 'HK>17,5', 10000),
('K', 'Kabinett', 10000),
('S', 'Saft', 10000),
('Z', 'Sekt', 10000);
INSERT INTO wine_cultivation VALUES
('N', 'Normal'),
('K', 'KIP'),
('B', 'Org. Biologisch');
-- Wien
-- Gemeinde Wien
INSERT INTO wb_gem VALUES
@ -112,7 +124,7 @@ SELECT k.kgnr, 1
FROM wb_gem wg
LEFT JOIN AT_gem g ON g.gkz = wg.gkz
LEFT JOIN AT_kg k ON k.gkz = g.gkz
WHERE origin = 'WLWV' AND g.gkz / 100 IN (308, 316) AND k.name IN
WHERE hkid = 'WLWV' AND g.gkz / 100 IN (308, 316) AND k.name IN
('Angern', 'Großschweinbarth', 'Mannersdorf', 'Prottes', 'Stillfried', 'Grub an der March', 'Auersthal', 'Dörfles',
'Ebenthal', 'Hohenruppersdorf', 'Kleinharras', 'Kollnbrunn', 'Matzen', 'Ollersdorf', 'Pirawarth', 'Raggendorf',
'Reyersdorf', 'Schönkirchen', 'Spannberg', 'Stripfing', 'Tallesbrunn', 'Götzendorf', 'Velm', 'Waidendorf',
@ -123,12 +135,12 @@ SELECT k.kgnr, 2
FROM wb_gem wg
LEFT JOIN AT_gem g ON g.gkz = wg.gkz
LEFT JOIN AT_kg k ON k.gkz = g.gkz
WHERE origin = 'WLWV' AND g.gkz / 100 IN (308, 316) AND k.name IN ('Bockfließ', 'Großengersdorf');
WHERE hkid = 'WLWV' AND g.gkz / 100 IN (308, 316) AND k.name IN ('Bockfließ', 'Großengersdorf');
INSERT INTO wb_kg
SELECT k.kgnr, 3
FROM wb_gem wg
LEFT JOIN AT_gem g ON g.gkz = wg.gkz
LEFT JOIN AT_kg k ON k.gkz = g.gkz
WHERE origin = 'WLWV' AND g.gkz / 100 IN (308, 316) AND
WHERE hkid = 'WLWV' AND g.gkz / 100 IN (308, 316) AND
k.name IN ('Erdpreß', 'Martinsdorf', 'Niedersulz', 'Großinzersdorf', 'Palterndorf');

View File

@ -40,33 +40,33 @@ CREATE TABLE postal_dest (
) STRICT;
CREATE TABLE wine_variety (
code TEXT NOT NULL CHECK (code REGEXP '[A-Z]{2}'),
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 (code)
CONSTRAINT pk_wine_variety PRIMARY KEY (sortid)
) STRICT;
CREATE TABLE AT_bundesland (
id INTEGER NOT NULL CHECK (id >= 0),
blnr INTEGER NOT NULL CHECK (blnr >= 0),
short1 TEXT NOT NULL,
short2 TEXT,
name TEXT NOT NULL,
CONSTRAINT pk_AT_bundesland PRIMARY KEY (id),
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),
land_id INTEGER NOT NULL GENERATED ALWAYS AS (gkz / 10000) VIRTUAL,
name TEXT NOT NULL,
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 (land_id) REFERENCES AT_bundesland (id)
CONSTRAINT fk_AT_gem_AT_bundesland FOREIGN KEY (blnr) REFERENCES AT_bundesland (blnr)
ON UPDATE CASCADE
ON DELETE RESTRICT
) STRICT;
@ -136,54 +136,54 @@ BEGIN
END;
CREATE TABLE wine_origin (
code TEXT NOT NULL CHECK (code REGEXP '[A-Z]{4}'),
parent_code TEXT,
hkid TEXT NOT NULL CHECK (hkid REGEXP '[A-Z]{4}'),
parent_hkid TEXT,
name TEXT NOT NULL,
land_id INTEGER,
blnr INTEGER,
CONSTRAINT pk_wine_origin PRIMARY KEY (code),
CONSTRAINT pk_wine_origin PRIMARY KEY (hkid),
CONSTRAINT sk_wine_origin_name UNIQUE (name),
CONSTRAINT fk_wine_origin_wine_origin FOREIGN KEY (parent_code) REFERENCES wine_origin (code)
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 (land_id) REFERENCES AT_bundesland (id)
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 (
id INTEGER NOT NULL,
glnr INTEGER NOT NULL,
name TEXT NOT NULL,
CONSTRAINT pk_wb_gl PRIMARY KEY (id)
CONSTRAINT pk_wb_gl PRIMARY KEY (glnr)
) STRICT;
-- Weinbaugemeinde
CREATE TABLE wb_gem (
gkz INTEGER NOT NULL,
origin TEXT NOT NULL,
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 (origin) REFERENCES wine_origin (code)
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,
gl_id INTEGER,
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 (gl_id) REFERENCES wb_gl (id)
CONSTRAINT fk_wb_gem_wb_gl FOREIGN KEY (glnr) REFERENCES wb_gl (glnr)
ON UPDATE CASCADE
ON DELETE RESTRICT
) STRICT;
@ -191,11 +191,11 @@ CREATE TABLE wb_kg (
-- Ried
CREATE TABLE wb_rd (
kgnr INTEGER NOT NULL,
rdid INTEGER NOT NULL,
rdnr INTEGER NOT NULL,
name TEXT NOT NULL,
CONSTRAINT pk_wb_rd PRIMARY KEY (kgnr, rdid),
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
@ -212,9 +212,37 @@ CREATE TABLE branch (
CONSTRAINT pk_branch PRIMARY KEY (zwstid)
);
CREATE TABLE wine_attribute (
attrid TEXT NOT NULL CHECK (attrid REGEXP '[A-Z]+'),
name TEXT NOT NULL,
kg_per_ha INTEGER NOT NULL DEFAULT 10000,
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 season (
year INTEGER NOT NULL CHECK (year >= 1000 AND year <= 9999),
currency TEXT NOT NULL,
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
);
CREATE TABLE member (
mgnr INTEGER NOT NULL,
predecessor_mgnr INTEGER DEFAULT NULL,
prefix TEXT DEFAULT NULL,
@ -222,49 +250,53 @@ CREATE TABLE member (
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,
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 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,
zwstid TEXT NOT 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,
betriebsnr TEXT DEFAULT NULL,
ustid TEXT CHECK (ustid REGEXP '[A-Z]{2}[A-Z0-9]{2,12}') DEFAULT NULL,
volllieferant INTEGER NOT NULL CHECK (volllieferant IN (FALSE, TRUE)) DEFAULT FALSE,
buchführend INTEGER NOT NULL CHECK (buchführend IN (FALSE, TRUE)) DEFAULT FALSE,
funktionär INTEGER NOT NULL CHECK (funktionär IN (FALSE, TRUE)) DEFAULT FALSE,
active INTEGER NOT NULL CHECK (active IN (FALSE, TRUE)) DEFAULT TRUE,
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,
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,
address TEXT NOT NULL,
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,
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_mobile REGEXP '\+[0-9]+') DEFAULT NULL,
comment TEXT DEFAULT NULL,
default_kgnr INTEGER NOT NULL,
default_zwstid TEXT NOT NULL,
comment TEXT DEFAULT NULL,
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 RESTRICT,
CONSTRAINT fk_member_branch FOREIGN KEY (default_zwstid) REFERENCES branch (zwstid)
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 TEXT NOT NULL,
@ -272,7 +304,53 @@ CREATE TABLE member_billing_address (
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)
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 contract (
vnr INTEGER NOT NULL,
mgnr INTEGER NOT NULL,
year_from INTEGER NOT NULL CHECK (year_from >= 1000 AND year_from <= 9999),
year_to INTEGER CHECK (year_to >= 1000 AND year_to <= 9999) DEFAULT NULL,
CONSTRAINT pk_contract PRIMARY KEY (vnr),
CONSTRAINT fk_contract_member FOREIGN KEY (mgnr) REFERENCES member (mgnr)
ON UPDATE CASCADE
ON DELETE RESTRICT
);
CREATE TABLE area_commitment (
vnr INTEGER NOT NULL,
kgnr INTEGER NOT NULL,
gstnr TEXT NOT NULL CHECK (gstnr REGEXP '\.?[1-9][0-9]*(/[1-9][0-9]*)*'),
rdnr INTEGER,
area INTEGER NOT NULL,
sortid TEXT NOT NULL,
attrid TEXT,
cultid TEXT NOT NULL,
CONSTRAINT pk_area_commitment PRIMARY KEY (vnr, kgnr, gstnr),
CONSTRAINT fk_area_commitment_contract FOREIGN KEY (vnr) REFERENCES contract (vnr)
ON UPDATE CASCADE
ON DELETE CASCADE,
CONSTRAINT fk_area_commitment_wine_variety FOREIGN KEY (sortid) REFERENCES wine_variety (sortid)
ON UPDATE CASCADE
ON DELETE RESTRICT,
CONSTRAINT fk_area_commitment_wine_attribute FOREIGN KEY (attrid) REFERENCES wine_attribute (attrid)
ON UPDATE CASCADE
ON DELETE RESTRICT,
CONSTRAINT fk_are_commitment_wine_cultivation FOREIGN KEY (cultid) REFERENCES wine_cultivation (cultid)
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;