Add AT_plz_dest table
This commit is contained in:
@ -90,6 +90,22 @@ CREATE TABLE AT_ort (
|
||||
) 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
|
||||
);
|
||||
|
||||
CREATE TABLE AT_plz_dest (
|
||||
plz INTEGER NOT NULL CHECK (plz >= 1000 AND plz <= 9999),
|
||||
okz INTEGER NOT NULL,
|
||||
|
||||
@ -98,30 +114,30 @@ CREATE TABLE AT_plz (
|
||||
|
||||
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)
|
||||
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_postal_dest FOREIGN KEY (country, id) REFERENCES postal_dest (country, id)
|
||||
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_i
|
||||
AFTER INSERT ON AT_plz FOR EACH ROW
|
||||
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_u
|
||||
AFTER UPDATE OF id ON AT_plz FOR EACH ROW
|
||||
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_d
|
||||
AFTER DELETE ON AT_plz FOR EACH ROW
|
||||
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;
|
||||
|
@ -3,4 +3,4 @@ CREATE VIEW v_plz AS
|
||||
SELECT plz, p.dest AS bestimmungsort, g.name AS gemeinde, g.gkz, o.name AS ort, o.okz
|
||||
FROM AT_gem g
|
||||
JOIN AT_ort o ON o.gkz = g.gkz
|
||||
JOIN AT_plz p ON p.okz = o.okz;
|
||||
JOIN AT_plz_dest p ON p.okz = o.okz;
|
||||
|
Reference in New Issue
Block a user