From ebebb9ae5943e53a3a3d420d2a572b6eb42ff1f9 Mon Sep 17 00:00:00 2001 From: Arnaud Poncet-Montanges Date: Fri, 25 Oct 2024 08:33:27 +0200 Subject: [PATCH] Add file and data_media classes to the datamodel, create vw_file To handle document management in TEKSI district heating --- datamodel/app/create_app.py | 2 +- datamodel/app/view/vw_file.sql | 170 ++++++++++++++++++ .../0001/03_tdh_db_data_media_file.sql | 67 +++++++ datamodel/scripts/setup.sh | 3 +- 4 files changed, 240 insertions(+), 2 deletions(-) create mode 100644 datamodel/app/view/vw_file.sql create mode 100644 datamodel/changelogs/0001/03_tdh_db_data_media_file.sql diff --git a/datamodel/app/create_app.py b/datamodel/app/create_app.py index 865759a..42debb3 100755 --- a/datamodel/app/create_app.py +++ b/datamodel/app/create_app.py @@ -109,7 +109,7 @@ def create_app( # additional views to be created with simple sql - # run_sql_file("view/vw_file.sql", pg_service, variables) + run_sql_file("view/vw_file.sql", pg_service, variables) # MultipleInheritance( # safe_load(open(cwd / "view/vw_oo_overflow.yaml")), diff --git a/datamodel/app/view/vw_file.sql b/datamodel/app/view/vw_file.sql new file mode 100644 index 0000000..5de8843 --- /dev/null +++ b/datamodel/app/view/vw_file.sql @@ -0,0 +1,170 @@ +-- ****************************************************************************** +-- Open/view files in tdh +-- ****************************************************************************** +--1. ADD fk_data_media : +-- ****************************************************************************** + +-- Modification of table od_file --> insert fk_data_media + +-- done in 04_vsa_kek_extension instead +--ALTER TABLE tdh_od.file ADD COLUMN fk_data_media character varying(16); + +-- ****************************************************************************** +-- 2. tdh_app.vw_file : +-- ****************************************************************************** + +-- View: tdh_app.vw_file + +CREATE OR REPLACE VIEW tdh_app.vw_file AS + SELECT f.obj_id, + f.identifier, + f.kind, + f.object, + f.classname, + -- dm.path, + COALESCE(dm.path::text || f.path_relative::text, f.path_relative::text) AS _url, + f.fk_dataowner as dataowner, + f.fk_provider as provider, + f.remark + FROM tdh_od.file f + LEFT JOIN tdh_od.data_media dm ON dm.obj_id::text = f.fk_data_media::text; + +ALTER VIEW tdh_app.vw_file ALTER obj_id SET DEFAULT tdh_app.generate_oid('tdh_od','file'); + +-- ****************************************************************************** +-- 3. FUNCTIONS : +-- ****************************************************************************** + +-- Function: tdh_app.vw_file_delete() +-- DROP FUNCTION tdh_app.vw_file_delete(); + +CREATE OR REPLACE FUNCTION tdh_app.vw_file_delete() + RETURNS trigger AS +$BODY$ + BEGIN + DELETE FROM tdh_od.file WHERE obj_id = OLD.obj_id; + RETURN OLD; + END; +$BODY$ +LANGUAGE plpgsql VOLATILE +COST 100; + + +-- ****************************************************************************** +-- Function: tdh_app.vw_file_insert() +-- DROP FUNCTION tdh_app.vw_file_insert(); +CREATE OR REPLACE FUNCTION tdh_app.vw_file_insert() + RETURNS trigger AS +$BODY$ + + BEGIN + + NEW._url = replace(NEW._url, '\', '/'); + + INSERT INTO tdh_od.file( + classname, + identifier, + kind, + object, + path_relative, + fk_dataowner, + fk_provider, + fk_data_media, + remark) + + SELECT + NEW.classname, + NEW.identifier, + NEW.kind, + NEW.object, + SUBSTRING(NEW._url, LENGTH("path")+1, LENGTH(NEW._url)), -- path_relative, + NEW.dataowner, -- fk_dataowner, + NEW.provider, -- fk_provider, + obj_id, -- fk_data_media + NEW.remark + FROM tdh_od.data_media + WHERE "path" = SUBSTRING(NEW._url FROM 1 FOR LENGTH("path")) + ORDER BY LENGTH("path") DESC + LIMIT 1; + + -- FOUND is a special variable which is always FALSE at the beginning of a PL/pgsql function and will be set by + -- e.g. INSERT to TRUE if at least one row is affected. + IF NOT FOUND THEN + RAISE WARNING 'Could not insert. File not in repository set in od_data_media!'; + END IF; + + RETURN NEW; +END; $BODY$ + LANGUAGE plpgsql VOLATILE + COST 100; + + -- ****************************************************************************** +-- Function: tdh_app.vw_file_update() +-- DROP FUNCTION tdh_app.vw_file_update(); + +CREATE OR REPLACE FUNCTION tdh_app.vw_file_update() + RETURNS trigger AS +$BODY$ +BEGIN + +NEW._url = replace(NEW._url, '\', '/'); + + UPDATE tdh_od.file + SET + classname = NEW.classname, + identifier = NEW.identifier, + kind = NEW.kind, + object = NEW.object, + path_relative = SUBSTRING(NEW._url, LENGTH(dm.path)+1, LENGTH(NEW._url)), + fk_dataowner = NEW.dataowner, + fk_provider = NEW.provider, + fk_data_media = dm.id, + remark = NEW.remark + +FROM ( + SELECT obj_id as id, + path + FROM tdh_od.data_media + WHERE path = SUBSTRING(NEW._url FROM 1 FOR LENGTH(path)) + ORDER BY LENGTH(path) DESC + LIMIT 1) dm + +WHERE obj_id = OLD.obj_id; + + + RETURN NEW; +END; +$BODY$ + LANGUAGE plpgsql VOLATILE + COST 100; + + +-- TRIGGERS : +-- ****************************************************************************** +-- Trigger: vw_file_delete on tdh_app.vw_file +-- DROP TRIGGER vw_file_delete ON tdh_app.vw_file; + +CREATE TRIGGER vw_file_delete + INSTEAD OF DELETE + ON tdh_app.vw_file + FOR EACH ROW + EXECUTE PROCEDURE tdh_app.vw_file_delete(); + +-- Trigger: vw_file_insert on tdh_app.vw_file +-- DROP TRIGGER vw_file_insert ON tdh_app.vw_file; + +CREATE TRIGGER vw_file_insert + INSTEAD OF INSERT + ON tdh_app.vw_file + FOR EACH ROW + EXECUTE PROCEDURE tdh_app.vw_file_insert(); + +-- Trigger: vw_file_update on tdh_app.vw_file +-- DROP TRIGGER vw_file_update ON tdh_app.vw_file; + +CREATE TRIGGER vw_file_update + INSTEAD OF UPDATE + ON tdh_app.vw_file + FOR EACH ROW + EXECUTE PROCEDURE tdh_app.vw_file_update(); +-- ****************************************************************************** diff --git a/datamodel/changelogs/0001/03_tdh_db_data_media_file.sql b/datamodel/changelogs/0001/03_tdh_db_data_media_file.sql new file mode 100644 index 0000000..d520dd0 --- /dev/null +++ b/datamodel/changelogs/0001/03_tdh_db_data_media_file.sql @@ -0,0 +1,67 @@ +------- Datamedia table using same structure as VSA KEK +------- +CREATE TABLE tdh_od.data_media +( + obj_id varchar(16) NOT NULL, + CONSTRAINT pkey_tdh_od_data_media_obj_id PRIMARY KEY (obj_id) +) +WITH ( + OIDS = False +); +CREATE SEQUENCE tdh_od.seq_data_media_oid INCREMENT 1 MINVALUE 0 MAXVALUE 999999 START 0; +COMMENT ON COLUMN tdh_od.data_media.obj_id IS 'INTERLIS STANDARD OID (with Postfix/Präfix), see www.interlis.ch'; + ALTER TABLE tdh_od.data_media ADD COLUMN identifier text; + ALTER TABLE tdh_od.data_media ADD CONSTRAINT vo_identifier_length_max_60 CHECK(char_length(identifier)<=60); +COMMENT ON COLUMN tdh_od.data_media.identifier IS 'yyy_Name des Datenträgers. Bei elektronischen Datenträgern normalerweise das Volume-Label. Bei einem Server der Servername. Bei analogen Videobändern die Bandnummer. / Name des Datenträgers. Bei elektronischen Datenträgern normalerweise das Volume-Label. Bei einem Server der Servername. Bei analogen Videobändern die Bandnummer. / Nom du support de données. Pour les supports de données électroniques, normalement le label volume. Pour un serveur, le nom du serveur. Pour des bandes vidéo analogiques, les numéros de bandes.'; + ALTER TABLE tdh_od.data_media ADD COLUMN kind integer ; +COMMENT ON COLUMN tdh_od.data_media.kind IS 'Describes the type of data media / Beschreibt die Art des Datenträgers / Décrit le genre de support de données'; + ALTER TABLE tdh_od.data_media ADD COLUMN location text; + ALTER TABLE tdh_od.data_media ADD CONSTRAINT vo_location_length_max_50 CHECK(char_length(location)<=50); +COMMENT ON COLUMN tdh_od.data_media.location IS 'Location of the data medium / Ort, wo sich der Datenträger befindet / Emplacement du support de données'; + ALTER TABLE tdh_od.data_media ADD COLUMN path text; + ALTER TABLE tdh_od.data_media ADD CONSTRAINT vo_path_length_max_1023 CHECK(char_length(path)<=1023); +COMMENT ON COLUMN tdh_od.data_media.path IS 'Access path to the data carrier. e.g. DVD drive -> D: , server -> //server/videos, hard disk -> c:/videos . For web servers -> URI (URL). Empty for an analog video tape / Zugriffspfad zum Datenträger. z.B. DVD-Laufwerk -> D: , Server -> //server/videos, Harddisk -> c:/videos . Bei Webserver eine URI (URL). Bei einem analogen Videoband leer / Chemin d’accès au support de données, p. ex. lecteur DVD -> D: , - serveur -> //server/videos , disque dur -> c:/videos , serveur_web -> URI(URL). Pour une bande vidéo analogique: vide'; + ALTER TABLE tdh_od.data_media ADD COLUMN remark text; + ALTER TABLE tdh_od.data_media ADD CONSTRAINT vo_remark_length_max_80 CHECK(char_length(remark)<=80); +COMMENT ON COLUMN tdh_od.data_media.remark IS 'General remarks / Bemerkungen zum Datenträger / Remarques concernant le support de données'; + ALTER TABLE tdh_od.data_media ADD COLUMN last_modification TIMESTAMP without time zone DEFAULT now(); +COMMENT ON COLUMN tdh_od.data_media.last_modification IS 'Last modification / Letzte_Aenderung / Derniere_modification: INTERLIS_1_DATE'; + ALTER TABLE tdh_od.data_media ADD COLUMN fk_dataowner varchar(16); +COMMENT ON COLUMN tdh_od.data_media.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 tdh_od.data_media ADD COLUMN fk_provider varchar(16); +COMMENT ON COLUMN tdh_od.data_media.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 '; + +-------File tabel using same structure as VSA KEK +------- +CREATE TABLE tdh_od.file +( + obj_id varchar(16) NOT NULL, + CONSTRAINT pkey_tdh_od_file_obj_id PRIMARY KEY (obj_id) +) +WITH ( + OIDS = False +); +CREATE SEQUENCE tdh_od.seq_file_oid INCREMENT 1 MINVALUE 0 MAXVALUE 999999 START 0; +COMMENT ON COLUMN tdh_od.file.obj_id IS 'INTERLIS STANDARD OID (with Postfix/Präfix), see www.interlis.ch'; + ALTER TABLE tdh_od.file ADD COLUMN classname integer ; +COMMENT ON COLUMN tdh_od.file.classname IS 'Specifies the classname of the VSA-DSS data model to which the file belongs. In principle, all classes are possible. In the context of sewer television recordings, mainly channel, manhole damage, channel damage and examination. / Gibt an, zu welcher Klasse des VSA-DSS-Datenmodells die Datei gehört. Grundsätzlich alle Klassen möglich. Im Rahmen der Kanalfernsehaufnahmen hauptsächlich Kanal, Normschachtschaden, Kanalschaden und Untersuchung. / Indique à quelle classe du modèle de données de VSA-SDEE appartient le fichier. Toutes les classes sont possible. Surtout CANALISATION, DOMMAGE_CHAMBRE_STANDARD, DOMMAGE_CANALISATION, EXAMEN.'; + ALTER TABLE tdh_od.file ADD COLUMN identifier text; + ALTER TABLE tdh_od.file ADD CONSTRAINT fi_identifier_length_max_120 CHECK(char_length(identifier)<=120); +COMMENT ON COLUMN tdh_od.file.identifier IS 'yyy_Name der Datei mit Dateiendung. Z.B video_01.mpg oder haltung_01.ipf / Name der Datei mit Dateiendung. Z.B video_01.mpg oder haltung_01.ipf / Nom du fichier avec terminaison du fichier. P. ex. video_01.mpg ou canalisation_01.ipf'; + ALTER TABLE tdh_od.file ADD COLUMN kind integer ; +COMMENT ON COLUMN tdh_od.file.kind IS 'yyy_Beschreibt die Art der Datei. Für analoge Videos auf Bändern ist der Typ "Video" einzusetzen. Die Bezeichnung wird dann gleich gesetzt wie die Bezeichnung des Videobandes. / Beschreibt die Art der Datei. Für analoge Videos auf Bändern ist der Typ "Video" einzusetzen. Die Bezeichnung wird dann gleich gesetzt wie die Bezeichnung des Videobandes. / Décrit le type de fichier. Pour les vidéos analo-giques sur bandes, le type « vidéo » doit être entré. La désignation sera ensuite la même que celle de la bande vidéo.'; + ALTER TABLE tdh_od.file ADD COLUMN object text; + ALTER TABLE tdh_od.file ADD CONSTRAINT fi_object_length_max_16 CHECK(char_length(object)<=16); +COMMENT ON COLUMN tdh_od.file.object IS 'yyy_Objekt-ID (OID) des Datensatzes zu dem die Datei gehört / Objekt-ID (OID) des Datensatzes zu dem die Datei gehört / Identification de l’ensemble de données auquel le fichier appartient (OID)'; + ALTER TABLE tdh_od.file ADD COLUMN path_relative text; + ALTER TABLE tdh_od.file ADD CONSTRAINT fi_path_relative_length_max_200 CHECK(char_length(path_relative)<=200); +COMMENT ON COLUMN tdh_od.file.path_relative IS 'yyy_Zusätzlicher Relativer Pfad, wo die Datei auf dem Datenträger zu finden ist. Z.B. DVD_01. / Zusätzlicher Relativer Pfad, wo die Datei auf dem Datenträger zu finden ist. Z.B. DVD_01. / Accès relatif supplémentaire à l’emplacement du fichier sur le support de données. P. ex. DVD_01'; + ALTER TABLE tdh_od.file ADD COLUMN remark text; + ALTER TABLE tdh_od.file ADD CONSTRAINT fi_remark_length_max_80 CHECK(char_length(remark)<=80); +COMMENT ON COLUMN tdh_od.file.remark IS 'General remarks / Allgemeine Bemerkungen / Remarques générales'; + ALTER TABLE tdh_od.file ADD COLUMN last_modification TIMESTAMP without time zone DEFAULT now(); +COMMENT ON COLUMN tdh_od.file.last_modification IS 'Last modification / Letzte_Aenderung / Derniere_modification: INTERLIS_1_DATE'; + ALTER TABLE tdh_od.file ADD COLUMN fk_dataowner varchar(16); +COMMENT ON COLUMN tdh_od.file.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 tdh_od.file ADD COLUMN fk_provider varchar(16); +COMMENT ON COLUMN tdh_od.file.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 '; diff --git a/datamodel/scripts/setup.sh b/datamodel/scripts/setup.sh index 664883a..8468f00 100755 --- a/datamodel/scripts/setup.sh +++ b/datamodel/scripts/setup.sh @@ -19,7 +19,8 @@ psql "service=${PGSERVICE}" -v ON_ERROR_STOP=1 -f ${DIR}/changelogs/0001/01_sche psql "service=${PGSERVICE}" -v ON_ERROR_STOP=1 -f ${DIR}/changelogs/0001/02_sys.sql psql "service=${PGSERVICE}" -v ON_ERROR_STOP=1 -f ${DIR}/changelogs/0001/oid_generation.sql -psql "service=${PGSERVICE}" -v ON_ERROR_STOP=1 -f ${DIR}/changelogs/0001/03_tdh_db_organisation.sql -v SRID=$SRID +psql "service=${PGSERVICE}" -v ON_ERROR_STOP=1 -f ${DIR}/changelogs/0001/03_tdh_db_organisation.sql +psql "service=${PGSERVICE}" -v ON_ERROR_STOP=1 -f ${DIR}/changelogs/0001/03_tdh_db_data_media_file.sql psql "service=${PGSERVICE}" -v ON_ERROR_STOP=1 -f ${DIR}/changelogs/0001/03_tdh_db_sia405.sql -v SRID=$SRID