Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

2024 10 29 add protection tube distant control cable #388

Open
wants to merge 40 commits into
base: master
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
Show all changes
40 commits
Select commit Hold shift + click to select a range
1af9f15
add protection tube
sjib Oct 29, 2024
c5f0e22
Add control cable
sjib Oct 29, 2024
4868958
Add dictionary / correct schemaprefixes
sjib Oct 29, 2024
a863f2c
Add oid_generation.sql
sjib Oct 29, 2024
3ec210c
init_qwat.sh / 02_sys.sql
sjib Oct 29, 2024
046758c
add 09_qwat_dictionaries.sql
sjib Oct 29, 2024
b3f46ba
create test_add_protection_tube.sql
sjib Oct 29, 2024
f201c19
Add class organisation
sjib Oct 29, 2024
1b434ae
init correct file path
sjib Oct 29, 2024
7ff2300
inherit from valuelistbase2
sjib Nov 13, 2024
132569f
correct schema name
sjib Nov 13, 2024
c34ffae
add reference from protection_tube to pipe
sjib Nov 16, 2024
b232486
adapt fk_pipe definition to fit qwat pipe.id
sjib Nov 16, 2024
b875cf6
correct schema
sjib Nov 16, 2024
331a3bf
correct cable_point.symbolori
sjib Nov 21, 2024
2e0e9ee
add sql for fk_folder relations
sjib Nov 21, 2024
fd538a8
adapt init_qwat.sh with fk_folder creation
sjib Nov 21, 2024
dd391ff
add deltas 1.4.2
sjib Nov 21, 2024
daeaa56
Update delta - add additional deltas and change order
sjib Nov 22, 2024
7701a02
Adapted SRID call for delta control_cable
sjib Nov 22, 2024
1df073e
adapt delta protection_tube
sjib Nov 22, 2024
d835892
comment out old statement
sjib Nov 22, 2024
bcdeeaa
END $$;
sjib Nov 22, 2024
ed64c6d
moved do $$ to end
sjib Nov 22, 2024
e9c5119
correct EXECUTE - wrong sql copied
sjib Nov 22, 2024
e7a3ce0
move back $$
sjib Nov 22, 2024
62dcc9e
add deltas for dictionaries
sjib Nov 22, 2024
75cbc35
Take out organisation prefixes - see https://github.com/teksi/wastewa…
sjib Dec 6, 2024
d64f255
add entry "unbekannt"
sjib Dec 7, 2024
0553681
Update comment protection_tube.nominal_diameter
sjib Dec 9, 2024
b36ecf7
adapt delta protection_tube
sjib Dec 9, 2024
ee9b7cd
adapt protection tube dictionary
sjib Dec 9, 2024
939b953
correct delta srid
sjib Dec 9, 2024
088d5c2
update qwat control cables comments
sjib Dec 9, 2024
0939061
missing quotation of '
sjib Dec 9, 2024
b483e76
more comments
sjib Dec 9, 2024
7be5e5e
Updates comments in delta
sjib Dec 9, 2024
f6d474b
update control cable dictionaries
sjib Dec 9, 2024
91409be
update delta control cable dictionaries
sjib Dec 9, 2024
c2b2d61
update delta protection tube dictionaries
sjib Dec 9, 2024
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
58 changes: 58 additions & 0 deletions demo/minimal_organisation.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,58 @@
/* qwat - Demo data organisation for sia405 control cable and protection tube*/

INSERT INTO qwat_od.organisation (
obj_id,
identifier,
identifier_short,
municipality_number,
organisation_type,
remark,
status,
uid,
last_modification,
fk_dataowner,
fk_provider
)
VALUES (
'ch20p3q400002114',
'Service intercommunal de gestion SIGE',
'SIGE',
NULL,
8608,
NULL,
9047,
'CHE108954487',
'20240906',
NULL,
NULL
);

INSERT INTO qwat_od.organisation (
obj_id,
identifier,
identifier_short,
municipality_number,
organisation_type,
remark,
status,
uid,
last_modification,
fk_dataowner,
fk_provider
)
VALUES (
'ch20p3q400000107',
'unbekannt',
'inconnu',
NULL,
8606, -- Privat
'Für alle Objekte mit unklarer Zuständigkeit',
9047,
'CHE108954487',
'20211116',
NULL,
NULL
);



20 changes: 20 additions & 0 deletions init_qwat.sh
Original file line number Diff line number Diff line change
Expand Up @@ -262,6 +262,26 @@ psql service=${PGSERVICE} -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/ordinary_da
echo "Starting tr_valve_pipe insertion..."
psql service=${PGSERVICE} -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/ordinary_data/valve/tr_valve_pipe.sql

echo "Starting organisation insertion..."
psql service=${PGSERVICE} -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/system/oid_generation.sql
psql service=${PGSERVICE} -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/system/02_sys.sql
psql service=${PGSERVICE} -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/system/09_qwat_dictionaries.sql

psql service=${PGSERVICE} -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/ordinary_data/organisation/03_qwat_db_organisation.sql
psql service=${PGSERVICE} -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/ordinary_data/organisation/09_qwat_organisation_dictionaries.sql

echo "Starting controlcable insertion..."
psql service=${PGSERVICE} -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/ordinary_data/controlcable/03_qwat_control_cable_db_sia405.sql
psql service=${PGSERVICE} -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/ordinary_data/controlcable/09_qwat_control_cable_dictionaries.sql
psql service=${PGSERVICE} -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/ordinary_data/controlcable/qwat_control_cable_fk_folder.sql

echo "Starting protection_tube insertion..."
psql service=${PGSERVICE} -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/ordinary_data/protectiontube/03_qwat_protection_tube_db_sia405.sql
psql service=${PGSERVICE} -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/ordinary_data/protectiontube/09_qwat_protection_tube_dictionaries.sql
psql service=${PGSERVICE} -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/ordinary_data/protectiontube/qwat_protection_tube_fk_folder.sql



echo "Starting view creation..."
PGSERVICE=${PGSERVICE} SRID=$SRID ${DIR}/ordinary_data/views/insert_views.sh

Expand Down
239 changes: 239 additions & 0 deletions ordinary_data/controlcable/03_qwat_control_cable_db_sia405.sql

Large diffs are not rendered by default.

96 changes: 96 additions & 0 deletions ordinary_data/controlcable/09_qwat_control_cable_dictionaries.sql

Large diffs are not rendered by default.

5 changes: 5 additions & 0 deletions ordinary_data/controlcable/qwat_control_cable_fk_folder.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,5 @@
ALTER TABLE qwat_od.sia405cc_cable ADD COLUMN fk_folder integer ;
ALTER TABLE qwat_od.sia405cc_cable ADD CONSTRAINT sia405cc_cable_fk_folder FOREIGN KEY (fk_folder) REFERENCES qwat_od.folder(id) MATCH FULL; CREATE INDEX fki_sia405cc_cable_fk_folder ON qwat_od.sia405cc_cable(fk_folder);

ALTER TABLE qwat_od.sia405cc_cable_point ADD COLUMN fk_folder integer ;
ALTER TABLE qwat_od.sia405cc_cable_point ADD CONSTRAINT sia405cc_cable_point_fk_folder FOREIGN KEY (fk_folder) REFERENCES qwat_od.folder(id) MATCH FULL; CREATE INDEX fki_sia405cc_cable_point_fk_folder ON qwat_od.sia405cc_cable_point(fk_folder);
110 changes: 110 additions & 0 deletions ordinary_data/organisation/03_qwat_db_organisation.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,110 @@
------ This file generates the database class organisation (Modul qwat (2020)) in en on QQIS
------ For questions etc. please contact Stefan Burckhardt [email protected]
------ version 10.04.2024 15:47:40
------ with 3D coordinates
BEGIN;

---- 03_qwat_db_organisation.sql ----------

---------------------------

CREATE TABLE qwat_vl.value_list_base2
(
code integer NOT NULL,
vsacode integer NOT NULL,
value_en character varying(100),
value_de character varying(100),
value_fr character varying(100),
value_it character varying(100),
value_ro character varying(100),
abbr_en character varying(3),
abbr_de character varying(3),
abbr_fr character varying(3),
abbr_it character varying(3),
abbr_ro character varying(3),
active boolean,
CONSTRAINT pkey_qwat_value_list_code PRIMARY KEY (code)
)
WITH (
OIDS = False
);
-------
-------

CREATE TABLE qwat_od.organisation
(
obj_id varchar(16) NOT NULL,
CONSTRAINT pkey_qwat_od_organisation_obj_id PRIMARY KEY (obj_id)
)
WITH (
OIDS = False
);
CREATE SEQUENCE qwat_od.seq_organisation_oid INCREMENT 1 MINVALUE 0 MAXVALUE 999999 START 0;
ALTER TABLE qwat_od.organisation ALTER COLUMN obj_id SET DEFAULT qwat_sys.generate_oid('qwat_od','organisation');
COMMENT ON COLUMN qwat_od.organisation.obj_id IS 'INTERLIS STANDARD OID (with Postfix/Präfix), see www.interlis.ch';
ALTER TABLE qwat_od.organisation ADD COLUMN identifier text;
ALTER TABLE qwat_od.organisation ADD CONSTRAINT og_identifier_length_max_255 CHECK(char_length(identifier)<=255);
COMMENT ON COLUMN qwat_od.organisation.identifier IS 'The designation for municipalities is adopted according to the FSO list; for private individuals according to the UID register, if necessary with the addition of the location of the branch if no separate UID exists for it. / Die Bezeichnung für Gemeinden wird gemäss BFS-Liste übernommen; für Private gemäss UID-Register, allenfalls mit Zusatz des Ortes der Filiale, falls keine separate UID dafür besteht. / La désignation pour les communes est reprise selon la liste de l''OFS ; pour les particuliers, selon le registre UID, éventuellement avec l''ajout du lieu de la filiale s''il n''existe pas d''UID séparé pour celle-ci.';
ALTER TABLE qwat_od.organisation ADD COLUMN identifier_short text;
ALTER TABLE qwat_od.organisation ADD CONSTRAINT og_identifier_short_length_max_12 CHECK(char_length(identifier_short)<=12);
COMMENT ON COLUMN qwat_od.organisation.identifier_short IS ' / Kurzbezeichnung / désignation abrégée';
ALTER TABLE qwat_od.organisation ADD COLUMN municipality_number smallint ;
COMMENT ON COLUMN qwat_od.organisation.municipality_number IS 'Official number of municipality of federal office for statistics, mandatory for the municipalities. / Offizielle Gemeinde Nummer gemäss Bundesamt für Statistik, bei Gemeinden zwingend, sonst leer lassen. / Numéro officiel de la commune selon l''Office fédéral de la statistique, obligatoire pour les communes. Sinon, laissez vide.';
ALTER TABLE qwat_od.organisation ADD COLUMN organisation_type integer ;
COMMENT ON COLUMN qwat_od.organisation.organisation_type IS 'Type of organisatoin / Art der Organisation / Genre d''organisation';
ALTER TABLE qwat_od.organisation ADD COLUMN remark text;
ALTER TABLE qwat_od.organisation ADD CONSTRAINT og_remark_length_max_255 CHECK(char_length(remark)<=255);
COMMENT ON COLUMN qwat_od.organisation.remark IS 'General remarks / Allgemeine Bemerkungen / Remarques générales';
ALTER TABLE qwat_od.organisation ADD COLUMN status integer ;
COMMENT ON COLUMN qwat_od.organisation.status IS 'yyy_Status der Organisation, damit untergegangende Organisationen nicht einfach gelöscht werden müssen und kontrolliert werden kann, ob noch Beziehungen auf untergegangene Organisationen, z.B. bei Gemeindefusion oder Konkurs einer Firma vorhanden sind / Status der Organisation, damit untergegangende Organisationen nicht einfach gelöscht werden müssen und kontrolliert werden kann, ob noch Beziehungen auf untergegangene Organisationen, z.B. bei Gemeindefusion oder Konkurs einer Firma vorhanden sind / Statut de l''organisation, pour que les organisations disparues ne soient pas simplement supprimées et qu''il soit possible de contrôler s''il existe encore des relations avec les organisations disparues, par exemple en cas de fusion de communes ou de faillite d''une société';
ALTER TABLE qwat_od.organisation ADD COLUMN uid text;
ALTER TABLE qwat_od.organisation ADD CONSTRAINT og_uid_length_max_12 CHECK(char_length(uid)<=12);
COMMENT ON COLUMN qwat_od.organisation.uid IS 'Reference to the company identification of the Federal Office for Statistics (www.uid.admin.ch), e.g. CHE123456789 / Referenz zur Unternehmensidentifikation des Bundesamts fuer Statistik (www.uid.admin.ch), z.B. CHE123456789 / Référence pour l’identification des entreprises selon l’Office fédéral de la statistique OFS (www.uid.admin.ch), par exemple: CHE123456789';
ALTER TABLE qwat_od.organisation ADD COLUMN last_modification TIMESTAMP without time zone DEFAULT now();
COMMENT ON COLUMN qwat_od.organisation.last_modification IS 'Last modification / Letzte_Aenderung / Derniere_modification: INTERLIS_1_DATE';
ALTER TABLE qwat_od.organisation ADD COLUMN fk_dataowner varchar(16);
COMMENT ON COLUMN qwat_od.organisation.fk_dataowner IS 'Foreignkey to Metaattribute dataowner (as an organisation) - this is the person or body who is allowed to delete, change or maintain this object / Metaattribut Datenherr ist diejenige Person oder Stelle, die berechtigt ist, diesen Datensatz zu löschen, zu ändern bzw. zu verwalten / Maître des données gestionnaire de données, qui est la personne ou l''organisation autorisée pour gérer, modifier ou supprimer les données de cette table/classe';
ALTER TABLE qwat_od.organisation ADD COLUMN fk_provider varchar(16);
COMMENT ON COLUMN qwat_od.organisation.fk_provider IS 'Foreignkey to Metaattribute provider (as an organisation) - this is the person or body who delivered the data / Metaattribut Datenlieferant ist diejenige Person oder Stelle, die die Daten geliefert hat / FOURNISSEUR DES DONNEES Organisation qui crée l’enregistrement de ces données ';
-------
CREATE TRIGGER
update_last_modified_organisation
BEFORE UPDATE OR INSERT ON
qwat_od.organisation
FOR EACH ROW EXECUTE PROCEDURE
qwat_sys.update_last_modified();

-------

------------ Relationships and Value Tables ----------- ;

CREATE TABLE qwat_vl.organisation_organisation_type () INHERITS (qwat_vl.value_list_base2);
ALTER TABLE qwat_vl.organisation_organisation_type ADD CONSTRAINT pkey_qwat_vl_organisation_organisation_type_code PRIMARY KEY (code);
INSERT INTO qwat_vl.organisation_organisation_type (code, vsacode, value_en, value_de, value_fr, value_it, value_ro, abbr_en, abbr_de, abbr_fr, abbr_it, abbr_ro, active) VALUES (8608,8608,'waste_water_association','Abwasserverband','association_epuration_eau', 'consorzio_depurazione', 'rrr_Abwasserverband', '', '', '', '', '', 'true');
INSERT INTO qwat_vl.organisation_organisation_type (code, vsacode, value_en, value_de, value_fr, value_it, value_ro, abbr_en, abbr_de, abbr_fr, abbr_it, abbr_ro, active) VALUES (8715,8715,'federation','Bund','federation', 'confederazione', 'rrr_Bund', '', '', '', '', '', 'true');
INSERT INTO qwat_vl.organisation_organisation_type (code, vsacode, value_en, value_de, value_fr, value_it, value_ro, abbr_en, abbr_de, abbr_fr, abbr_it, abbr_ro, active) VALUES (8604,8604,'municipality','Gemeinde','commune', 'comune', 'municipiul', '', '', '', '', '', 'true');
INSERT INTO qwat_vl.organisation_organisation_type (code, vsacode, value_en, value_de, value_fr, value_it, value_ro, abbr_en, abbr_de, abbr_fr, abbr_it, abbr_ro, active) VALUES (9319,9319,'municipal_department','Gemeindeabteilung','departement_communal', 'dipartimento_comunale', 'departamentul_municipal', '', '', '', '', '', 'true');
INSERT INTO qwat_vl.organisation_organisation_type (code, vsacode, value_en, value_de, value_fr, value_it, value_ro, abbr_en, abbr_de, abbr_fr, abbr_it, abbr_ro, active) VALUES (8610,8610,'cooperative','Genossenschaft_Korporation','cooperative', 'cooperativa_corporazione', 'rrr_Genossenschaft_Korporation', '', '', '', '', '', 'true');
INSERT INTO qwat_vl.organisation_organisation_type (code, vsacode, value_en, value_de, value_fr, value_it, value_ro, abbr_en, abbr_de, abbr_fr, abbr_it, abbr_ro, active) VALUES (8605,8605,'canton','Kanton','canton', 'cantone', 'rrr_Kanton', '', '', '', '', '', 'true');
INSERT INTO qwat_vl.organisation_organisation_type (code, vsacode, value_en, value_de, value_fr, value_it, value_ro, abbr_en, abbr_de, abbr_fr, abbr_it, abbr_ro, active) VALUES (8606,8606,'private','Privat','prive', 'privato', 'privata', '', '', '', '', '', 'true');
ALTER TABLE qwat_od.organisation ADD CONSTRAINT fkey_vl_organisation_organisation_type FOREIGN KEY (organisation_type)
REFERENCES qwat_vl.organisation_organisation_type (code) MATCH SIMPLE
ON UPDATE RESTRICT ON DELETE RESTRICT;
CREATE TABLE qwat_vl.organisation_status () INHERITS (qwat_vl.value_list_base2);
ALTER TABLE qwat_vl.organisation_status ADD CONSTRAINT pkey_qwat_vl_organisation_status_code PRIMARY KEY (code);
INSERT INTO qwat_vl.organisation_status (code, vsacode, value_en, value_de, value_fr, value_it, value_ro, abbr_en, abbr_de, abbr_fr, abbr_it, abbr_ro, active) VALUES (9047,9047,'activ','aktiv','active', 'attivo', 'rrr_aktiv', '', '', '', '', '', 'true');
INSERT INTO qwat_vl.organisation_status (code, vsacode, value_en, value_de, value_fr, value_it, value_ro, abbr_en, abbr_de, abbr_fr, abbr_it, abbr_ro, active) VALUES (9048,9048,'gone','untergegangen','disparue', 'decaduta', 'rrr_untergegangen', '', '', '', '', '', 'true');
ALTER TABLE qwat_od.organisation ADD CONSTRAINT fkey_vl_organisation_status FOREIGN KEY (status)
REFERENCES qwat_vl.organisation_status (code) MATCH SIMPLE
ON UPDATE RESTRICT ON DELETE RESTRICT;

--------- Relations to class organisation for dataowner and provider (new 3.11.2014);

ALTER TABLE qwat_od.organisation ADD CONSTRAINT rel_od_organisation_fk_dataowner FOREIGN KEY (fk_dataowner) REFERENCES qwat_od.organisation(obj_id) DEFERRABLE INITIALLY DEFERRED;
ALTER TABLE qwat_od.organisation ADD CONSTRAINT rel_od_organisation_fk_dataprovider FOREIGN KEY (fk_provider) REFERENCES qwat_od.organisation(obj_id) DEFERRABLE INITIALLY DEFERRED;

----- Indexes on identifiers

CREATE UNIQUE INDEX in_od_organisation_identifier ON qwat_od.organisation USING btree (identifier ASC NULLS LAST, fk_dataowner ASC NULLS LAST);

COMMIT;
Loading
Loading