Add member table
This commit is contained in:
@ -4,6 +4,9 @@ INSERT INTO wb_gl VALUES
|
|||||||
(2, 'Wolkersdorfer Hochleiten'),
|
(2, 'Wolkersdorfer Hochleiten'),
|
||||||
(3, 'Falkensteiner Hügelland');
|
(3, 'Falkensteiner Hügelland');
|
||||||
|
|
||||||
|
INSERT INTO branch VALUES
|
||||||
|
('M', 'Matzen');
|
||||||
|
|
||||||
-- Wien
|
-- Wien
|
||||||
-- Gemeinde Wien
|
-- Gemeinde Wien
|
||||||
INSERT INTO wb_gem VALUES
|
INSERT INTO wb_gem VALUES
|
||||||
|
@ -200,3 +200,79 @@ CREATE TABLE wb_rd (
|
|||||||
ON UPDATE CASCADE
|
ON UPDATE CASCADE
|
||||||
ON DELETE RESTRICT
|
ON DELETE RESTRICT
|
||||||
) STRICT;
|
) 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;
|
||||||
|
Reference in New Issue
Block a user