diff --git a/.travis.yml b/.travis.yml index ebb95450..5efaa041 100644 --- a/.travis.yml +++ b/.travis.yml @@ -47,7 +47,7 @@ before_script: script: - $TRAVIS_BUILD_DIR/scripts/db_setup.sh -r > /dev/null - - nosetests -e test_import.py + - nosetests -e test_import.py -e test_geometry.py # Get current version - export VERSION=$(sed 'r' "$TRAVIS_BUILD_DIR/system/CURRENT_VERSION.txt") diff --git a/03_qgep_db_dss.sql b/03_qgep_db_dss.sql index 46ca1590..6c9d77a3 100644 --- a/03_qgep_db_dss.sql +++ b/03_qgep_db_dss.sql @@ -1825,7 +1825,7 @@ ALTER TABLE qgep_od.reach_point ADD COLUMN position_of_connection smallint ; COMMENT ON COLUMN qgep_od.reach_point.position_of_connection IS 'yyy_Anschlussstelle bezogen auf Querschnitt im Kanal; in Fliessrichtung (für Haus- und Strassenanschlüsse) / Anschlussstelle bezogen auf Querschnitt im Kanal; in Fliessrichtung (für Haus- und Strassenanschlüsse) / Emplacement de raccordement Référence à la section transversale dans le canal dans le sens d’écoulement (pour les raccordements domestiques et de rue).'; ALTER TABLE qgep_od.reach_point ADD COLUMN remark varchar(80) ; COMMENT ON COLUMN qgep_od.reach_point.remark IS 'General remarks / Allgemeine Bemerkungen / Remarques générales'; -ALTER TABLE qgep_od.reach_point ADD COLUMN situation_geometry geometry('POINT', :SRID); +ALTER TABLE qgep_od.reach_point ADD COLUMN situation_geometry geometry('POINTZ', :SRID); CREATE INDEX in_qgep_od_reach_point_situation_geometry ON qgep_od.reach_point USING gist (situation_geometry ); COMMENT ON COLUMN qgep_od.reach_point.situation_geometry IS 'National position coordinates (East, North) / Landeskoordinate Ost/Nord / Coordonnées nationales Est/Nord'; ALTER TABLE qgep_od.reach_point ADD COLUMN last_modification TIMESTAMP without time zone DEFAULT now(); @@ -1859,7 +1859,7 @@ ALTER TABLE qgep_od.wastewater_node ADD COLUMN backflow_level decimal(7,3) ; COMMENT ON COLUMN qgep_od.wastewater_node.backflow_level IS 'yyy_1. Massgebende Rückstaukote bezogen auf den Berechnungsregen (dss) 2. Höhe, unter der innerhalb der Grundstücksentwässerung besondere Massnahmen gegen Rückstau zu treffen sind. (DIN 4045) / 1. Massgebende Rückstaukote bezogen auf den Berechnungsregen (dss) 2. Höhe, unter der innerhalb der Grundstücksentwässerung besondere Massnahmen gegen Rückstau zu treffen sind. (DIN 4045) / Cote de refoulement déterminante calculée à partir des pluies de projet'; ALTER TABLE qgep_od.wastewater_node ADD COLUMN bottom_level decimal(7,3) ; COMMENT ON COLUMN qgep_od.wastewater_node.bottom_level IS 'yyy_Tiefster Punkt des Abwasserbauwerks / Tiefster Punkt des Abwasserbauwerks / Point le plus bas du noeud'; -ALTER TABLE qgep_od.wastewater_node ADD COLUMN situation_geometry geometry('POINT', :SRID); +ALTER TABLE qgep_od.wastewater_node ADD COLUMN situation_geometry geometry('POINTZ', :SRID); CREATE INDEX in_qgep_od_wastewater_node_situation_geometry ON qgep_od.wastewater_node USING gist (situation_geometry ); COMMENT ON COLUMN qgep_od.wastewater_node.situation_geometry IS 'yyy Situation of node. Decisive reference point for sewer network simulation (In der Regel Lage des Pickellochs oder Lage des Trockenwetterauslauf) / Lage des Knotens, massgebender Bezugspunkt für die Kanalnetzberechnung. (In der Regel Lage des Pickellochs oder Lage des Trockenwetterauslaufs) / Positionnement du nœud. Point de référence déterminant pour le calcul de réseau de canalisations (en règle générale positionnement du milieu du couvercle ou de la sortie temps sec)'; ------- @@ -2255,7 +2255,7 @@ ALTER TABLE qgep_od.cover ADD COLUMN material integer ; COMMENT ON COLUMN qgep_od.cover.material IS 'Material of cover / Deckelmaterial / Matériau du couvercle'; ALTER TABLE qgep_od.cover ADD COLUMN positional_accuracy integer ; COMMENT ON COLUMN qgep_od.cover.positional_accuracy IS 'Quantfication of accuarcy of position of cover (center hole) / Quantifizierung der Genauigkeit der Lage des Deckels (Pickelloch) / Plage de précision des coordonnées planimétriques du couvercle.'; -ALTER TABLE qgep_od.cover ADD COLUMN situation_geometry geometry('POINT', :SRID); +ALTER TABLE qgep_od.cover ADD COLUMN situation_geometry geometry('POINTZ', :SRID); CREATE INDEX in_qgep_od_cover_situation_geometry ON qgep_od.cover USING gist (situation_geometry ); COMMENT ON COLUMN qgep_od.cover.situation_geometry IS 'Situation of cover (cover hole), National position coordinates (East, North) / Lage des Deckels (Pickelloch) / Positionnement du couvercle (milieu du couvercle)'; ALTER TABLE qgep_od.cover ADD COLUMN sludge_bucket integer ; diff --git a/07_views_for_network_tracking.sql b/07_views_for_network_tracking.sql index c8a06442..9fbf1ddf 100644 --- a/07_views_for_network_tracking.sql +++ b/07_views_for_network_tracking.sql @@ -18,8 +18,8 @@ CREATE MATERIALIZED VIEW qgep_od.vw_network_node AS NULL AS cover_level, NULL AS backflow_level, NULL AS description, - situation_geometry::geometry(Point,:SRID) AS detail_geometry, - situation_geometry::geometry(Point,:SRID) + situation_geometry::geometry(POINTZ,:SRID) AS detail_geometry, + situation_geometry::geometry(POINTZ,:SRID) FROM qgep_od.reach_point UNION diff --git a/13_import.sql b/13_import.sql index 4c8ada96..5aa78167 100644 --- a/13_import.sql +++ b/13_import.sql @@ -6,7 +6,7 @@ CREATE TABLE qgep_import.manhole_quarantine ( obj_id character varying(16), identifier character varying(20), - situation_geometry geometry(Point,:SRID), + situation_geometry geometry(POINTZ,:SRID), co_shape integer, co_diameter smallint, co_material integer, @@ -57,7 +57,7 @@ CREATE TABLE qgep_import.manhole_quarantine CREATE OR REPLACE VIEW qgep_import.vw_manhole AS SELECT DISTINCT ON (ws.obj_id) ws.obj_id, ws.identifier, - (st_dump(ws.situation_geometry)).geom::geometry(Point,:SRID) AS situation_geometry, + (st_dump(ws.situation_geometry)).geom::geometry(POINTZ,:SRID) AS situation_geometry, ws.co_shape, ws.co_diameter, ws.co_material, @@ -224,9 +224,9 @@ BEGIN EXECUTE format($TRIGGER$ CREATE OR REPLACE FUNCTION qgep_import.manhole_quarantine_try_structure_update() RETURNS trigger AS $BODY$ DECLARE - multi_situation_geometry geometry(MultiPoint,%1$s); + multi_situation_geometry geometry(MULTIPOINTZ,%1$s); BEGIN - multi_situation_geometry = st_collect(NEW.situation_geometry)::geometry(MultiPoint,%1$s); + multi_situation_geometry = st_collect(NEW.situation_geometry)::geometry(MULTIPOINTZ,%1$s); -- in case there is a depth, but no refercing value - it should stay in quarantene IF( NEW._depth IS NOT NULL AND NEW.co_level IS NULL AND NEW.wn_bottom_level IS NULL ) THEN diff --git a/14_geometry_functions.sql b/14_geometry_functions.sql new file mode 100644 index 00000000..e5b4fc52 --- /dev/null +++ b/14_geometry_functions.sql @@ -0,0 +1,89 @@ +----------------------------------------------- +----------------------------------------------- +-- Synchronize GEOMETRY with bottom_level qgep_od.wastewater_node +----------------------------------------------- +----------------------------------------------- +SELECT set_config('qgep.srid', :SRID::text, false); +DO $DO$ +BEGIN +EXECUTE format($TRIGGER$ +CREATE OR REPLACE FUNCTION qgep_od.synchronize_level_with_altitude_on_wastewater_node() + RETURNS trigger AS +$BODY$ +BEGIN + CASE + WHEN TG_OP = 'INSERT' THEN + NEW.situation_geometry = ST_SetSRID( ST_MakePoint( ST_X(NEW.situation_geometry), ST_Y(NEW.situation_geometry), COALESCE(NEW.bottom_level,'NaN') ), %1$s); + WHEN TG_OP = 'UPDATE' THEN + IF NEW.bottom_level <> OLD.bottom_level OR (NEW.bottom_level IS NULL AND OLD.bottom_level IS NOT NULL) OR (NEW.bottom_level IS NOT NULL AND OLD.bottom_level IS NULL) THEN + NEW.situation_geometry = ST_SetSRID( ST_MakePoint( ST_X(NEW.situation_geometry), ST_Y(NEW.situation_geometry), COALESCE(NEW.bottom_level,'NaN') ), %1$s); + ELSE + IF ST_Z(NEW.situation_geometry) <> ST_Z(OLD.situation_geometry) THEN + NEW.bottom_level = NULLIF(ST_Z(NEW.situation_geometry),'NaN'); + END IF; + END IF; + END CASE; + + RETURN NEW; +END; $BODY$ + LANGUAGE plpgsql VOLATILE; +$TRIGGER$, current_setting('qgep.srid')); +END +$DO$; + +DROP TRIGGER IF EXISTS synchronize_level_with_altitude ON qgep_od.wastewater_node; + +CREATE TRIGGER synchronize_level_with_altitude + BEFORE INSERT OR UPDATE + ON qgep_od.wastewater_node + FOR EACH ROW + EXECUTE PROCEDURE qgep_od.synchronize_level_with_altitude_on_wastewater_node(); + + +----------------------------------------------- +----------------------------------------------- +-- Synchronize GEOMETRY with level qgep_od.cover +----------------------------------------------- +----------------------------------------------- +SELECT set_config('qgep.srid', :SRID::text, false); +DO $DO$ +BEGIN +EXECUTE format($TRIGGER$ +CREATE OR REPLACE FUNCTION qgep_od.synchronize_level_with_altitude_on_cover() + RETURNS trigger AS +$BODY$ +BEGIN + CASE + WHEN TG_OP = 'INSERT' THEN + NEW.situation_geometry = ST_SetSRID( ST_MakePoint( ST_X(NEW.situation_geometry), ST_Y(NEW.situation_geometry), COALESCE(NEW.level,'NaN') ), %1$s); + WHEN TG_OP = 'UPDATE' THEN + IF NEW.level <> OLD.level OR (NEW.level IS NULL AND OLD.level IS NOT NULL) OR (NEW.level IS NOT NULL AND OLD.level IS NULL) THEN + NEW.situation_geometry = ST_SetSRID( ST_MakePoint( ST_X(NEW.situation_geometry), ST_Y(NEW.situation_geometry), COALESCE(NEW.level,'NaN') ), %1$s); + ELSE + IF ST_Z(NEW.situation_geometry) <> ST_Z(OLD.situation_geometry) THEN + NEW.level = NULLIF(ST_Z(NEW.situation_geometry),'NaN'); + END IF; + END IF; + END CASE; + + RETURN NEW; +END; $BODY$ + LANGUAGE plpgsql VOLATILE; +$TRIGGER$, current_setting('qgep.srid')); +END +$DO$; + +DROP TRIGGER IF EXISTS synchronize_level_with_altitude ON qgep_od.cover; + +CREATE TRIGGER synchronize_level_with_altitude + BEFORE INSERT OR UPDATE + ON qgep_od.cover + FOR EACH ROW + EXECUTE PROCEDURE qgep_od.synchronize_level_with_altitude_on_cover(); + + +----------------------------------------------- +----------------------------------------------- +-- Synchronize reach and reach_point GEOMETRY with level qgep_od.vw_qgep_reach is implemented in vw_qgep_reach.sql +----------------------------------------------- +----------------------------------------------- \ No newline at end of file diff --git a/delta/delta_1.1.2_geometry_altitude.post.sql b/delta/delta_1.1.2_geometry_altitude.post.sql new file mode 100644 index 00000000..8050fcb6 --- /dev/null +++ b/delta/delta_1.1.2_geometry_altitude.post.sql @@ -0,0 +1,1401 @@ +----------------------------------------------- +----------------------------------------------- +-- UPDATE GEOMETRY OF qgep_od.reach_point +----------------------------------------------- +----------------------------------------------- +DROP MATERIALIZED VIEW IF EXISTS qgep_od.vw_network_segment; +DROP MATERIALIZED VIEW IF EXISTS qgep_od.vw_network_node; +DROP VIEW IF EXISTS qgep_od.vw_qgep_reach; +DROP VIEW IF EXISTS qgep_od.vw_change_points; + +ALTER TABLE qgep_od.reach_point ALTER COLUMN situation_geometry TYPE geometry('POINTZ', %(SRID)s) USING ST_SetSRID( ST_MakePoint( ST_X(situation_geometry), ST_Y(situation_geometry), COALESCE(level,'NaN') ), %(SRID)s); + + + + +----------------------------------------------- +----------------------------------------------- +-- UPDATE GEOMETRY OF qgep_od.wastewater_node +----------------------------------------------- +----------------------------------------------- +DROP VIEW IF EXISTS qgep_od.vw_qgep_overflow; +DROP VIEW IF EXISTS qgep_od.vw_catchment_area_connections; +DROP VIEW IF EXISTS qgep_import.vw_manhole; +DROP VIEW IF EXISTS qgep_od.vw_qgep_wastewater_structure; +DROP VIEW IF EXISTS qgep_od.vw_wastewater_node; + +ALTER TABLE qgep_od.wastewater_node ALTER COLUMN situation_geometry TYPE geometry('POINTZ', %(SRID)s) USING ST_SetSRID( ST_MakePoint( ST_X(situation_geometry), ST_Y(situation_geometry), COALESCE(bottom_level,'NaN') ), %(SRID)s); +-- in quarantine we do not add the level to the geometry because this will be done on insert on table - so it's always 'NaN' +ALTER TABLE qgep_import.manhole_quarantine ALTER COLUMN situation_geometry TYPE geometry('POINTZ', %(SRID)s) USING ST_SetSRID( ST_MakePoint( ST_X(situation_geometry), ST_Y(situation_geometry), 'NaN' ), %(SRID)s); + + + + +----------------------------------------------- +----------------------------------------------- +-- UPDATE GEOMETRY OF qgep_od.cover +----------------------------------------------- +----------------------------------------------- +DROP VIEW IF EXISTS qgep_od.vw_cover; + +ALTER TABLE qgep_od.cover ALTER COLUMN situation_geometry TYPE geometry('POINTZ', %(SRID)s) USING ST_SetSRID( ST_MakePoint( ST_X(situation_geometry), ST_Y(situation_geometry), COALESCE(level,'NaN') ), %(SRID)s); + + + + +----------------------------------------------- +----------------------------------------------- +-- RECREATE DEPENDENCIES OF qgep_od.reach_point +----------------------------------------------- +----------------------------------------------- +-- View: qgep_od.vw_network_node +----------------------------------------------- + +CREATE MATERIALIZED VIEW qgep_od.vw_network_node AS + SELECT + row_number() OVER () AS gid, + nodes.* + FROM + ( + SELECT + obj_id, + 'reach_point' AS type, + 'reach_point' AS node_type, + level AS level, + NULL AS usage_current, + NULL AS cover_level, + NULL AS backflow_level, + NULL AS description, + situation_geometry::geometry(POINTZ,%(SRID)s) AS detail_geometry, + situation_geometry::geometry(POINTZ,%(SRID)s) + FROM qgep_od.reach_point + + UNION + + SELECT + NE.obj_id, + 'wastewater_node' AS type, + CASE + WHEN MH.obj_id IS NOT NULL + THEN 'manhole' + WHEN WS.obj_id IS NOT NULL + THEN 'special_WSucture' + ELSE 'other' + END AS node_type, + bottom_level AS level, + COALESCE( MAX( ch_from.usage_current ), MAX( ch_to.usage_current ) ) AS usage_current, + MAX( CO.level ) AS cover_level, + WN.backflow_level AS backflow_level, + NE.identifier AS description, + COALESCE( WS.detail_geometry_geometry, WN.situation_geometry ) AS detail_geometry, -- Will contain different geometry types: do not visualize directly. Will be handled by plugin + WN.situation_geometry + FROM qgep_od.wastewater_node WN + LEFT JOIN qgep_od.wastewater_networkelement NE + ON NE.obj_id = WN.obj_id + LEFT JOIN qgep_od.wastewater_structure WS + ON WS.obj_id = NE.fk_wastewater_structure + LEFT JOIN qgep_od.manhole MH + ON MH.obj_id = WS.obj_id + LEFT JOIN qgep_od.structure_part SP + ON SP.fk_wastewater_structure = WS.obj_id + LEFT JOIN qgep_od.cover CO + ON CO.obj_id = SP.obj_id + LEFT JOIN qgep_od.reach_point RP + ON NE.obj_id = RP.fk_wastewater_networkelement + LEFT JOIN qgep_od.reach re_from + ON re_from.fk_reach_point_from = RP.obj_id + LEFT JOIN qgep_od.wastewater_networkelement ne_from + ON ne_from.obj_id = re_from.obj_id + LEFT JOIN qgep_od.channel ch_from + ON ch_from.obj_id = ne_from.fk_wastewater_structure + LEFT JOIN qgep_od.reach re_to + ON re_to.fk_reach_point_to = RP.obj_id + LEFT JOIN qgep_od.wastewater_networkelement ne_to + ON ne_to.obj_id = re_to.obj_id + LEFT JOIN qgep_od.channel ch_to + ON ch_to.obj_id = ne_to.fk_wastewater_structure + GROUP BY NE.obj_id, type, bottom_level, backflow_level, description, WN.situation_geometry, WS.detail_geometry_geometry, WS.obj_id, MH.obj_id, SP.fk_wastewater_structure + ) AS nodes; + + + + +----------------------------------------------- +-- View: qgep_od.vw_network_segment +----------------------------------------------- + +CREATE MATERIALIZED VIEW qgep_od.vw_network_segment AS + WITH reach_parts AS ( + SELECT + row_number() OVER (ORDER BY reach_point.fk_wastewater_networkelement, ST_LineLocatePoint(ST_LineMerge(ST_CurveToLine(ST_Force2D(reach.progression_geometry))), reach_point.situation_geometry)) AS gid, + reach_point.obj_id, + reach_point.fk_wastewater_networkelement, + reach_point.situation_geometry, + reach.progression_geometry, + reach.fk_reach_point_from, + reach.fk_reach_point_to, + ST_LineMerge(ST_CurveToLine(ST_Force2D(reach.progression_geometry))) AS reach_progression, + ST_LineLocatePoint( + ST_LineMerge(ST_CurveToLine(ST_Force2D(reach.progression_geometry))), + reach_point.situation_geometry + ) AS pos + FROM qgep_od.reach_point + LEFT JOIN qgep_od.reach ON reach_point.fk_wastewater_networkelement::text = reach.obj_id::text + WHERE reach_point.fk_wastewater_networkelement IS NOT NULL AND reach.progression_geometry IS NOT NULL + ORDER BY reach_point.obj_id, ST_LineLocatePoint(ST_LineMerge(ST_CurveToLine(reach.progression_geometry)), reach_point.situation_geometry) + ) + + SELECT row_number() OVER () AS gid, + parts.* + FROM + ( + SELECT + re.obj_id, + 'reach' AS type, + clear_height, + ST_Length( COALESCE( reach_progression, progression_geometry ) ) AS length_calc, + ST_Length( progression_geometry ) AS length_full, + COALESCE( from_obj_id, fk_reach_point_from ) AS from_obj_id, + COALESCE( to_obj_id, fk_reach_point_to ) AS to_obj_id, + fk_reach_point_from AS from_obj_id_interpolate, + fk_reach_point_to AS to_obj_id_interpolate, + COALESCE( from_pos, 0 ) AS from_pos, + COALESCE( to_pos, 1 ) AS to_pos, + NULL AS bottom_level, + ch.usage_current AS usage_current, + mat.abbr_de AS material, + COALESCE(reach_progression, ST_LineMerge(ST_CurveToLine(ST_Force2D(progression_geometry)))) AS progression_geometry, + ST_LineMerge(ST_CurveToLine(ST_Force2D(progression_geometry)))::geometry(LineString,%(SRID)s) AS detail_geometry + FROM qgep_od.reach re + FULL JOIN + ( + SELECT + COALESCE(s1.fk_wastewater_networkelement, s2.fk_wastewater_networkelement) AS reach_obj_id, + COALESCE(s1.obj_id, s2.fk_reach_point_from) AS from_obj_id, + COALESCE(s2.obj_id, s1.fk_reach_point_to) AS to_obj_id, + COALESCE(s1.pos, 0::double precision) AS from_pos, + COALESCE(s2.pos, 1::double precision) AS to_pos, + ST_LineSubstring(COALESCE(s1.reach_progression, s2.reach_progression), + COALESCE(s1.pos, 0::double precision), + COALESCE(s2.pos, 1::double precision)) AS reach_progression + FROM reach_parts s1 + FULL JOIN reach_parts s2 ON s1.gid = (s2.gid - 1) AND s1.fk_wastewater_networkelement::text = s2.fk_wastewater_networkelement::text + ORDER BY COALESCE(s1.fk_wastewater_networkelement, s2.fk_wastewater_networkelement), COALESCE(s1.pos, 0::double precision) + ) AS rr + ON rr.reach_obj_id = re.obj_id + LEFT JOIN qgep_od.wastewater_networkelement ne ON ne.obj_id = re.obj_id + LEFT JOIN qgep_od.channel ch ON ch.obj_id = ne.fk_wastewater_structure + LEFT JOIN qgep_vl.reach_material mat ON re.material = mat.code + + UNION + + SELECT + connectors.obj_id AS obj_id, + 'special_structure' AS type, + NULL AS depth, + ST_Length( progression_geometry ) AS length_calc, + ST_Length( progression_geometry ) AS length_full, + from_obj_id, + to_obj_id, + from_obj_id AS from_obj_id_interpolate, + to_obj_id AS to_obj_id_interpolate, + 0 AS from_pos, + 1 AS to_pos, + bottom_level, + NULL AS usage_current, + NULL AS material, + progression_geometry, + progression_geometry AS detail_geometry + + FROM + ( + SELECT + wn_from.obj_id AS obj_id, + wn_from.obj_id AS from_obj_id, + rp_from.obj_id AS to_obj_id, + wn_from.bottom_level AS bottom_level, + ST_LineFromMultiPoint( ST_Collect(wn_from.situation_geometry, rp_from.situation_geometry ) ) AS progression_geometry + FROM qgep_od.reach + LEFT JOIN qgep_od.reach_point rp_from ON rp_from.obj_id = reach.fk_reach_point_from + LEFT JOIN qgep_od.wastewater_node wn_from ON rp_from.fk_wastewater_networkelement = wn_from.obj_id + WHERE + reach.fk_reach_point_from IS NOT NULL + AND + wn_from.obj_id IS NOT NULL + + UNION + + SELECT + wn_to.obj_id AS obj_id, + rp_to.obj_id AS from_obj_id, + wn_to.obj_id AS to_obj_id, + wn_to.bottom_level AS bottom_level, + ST_LineFromMultiPoint( ST_Collect(rp_to.situation_geometry, wn_to.situation_geometry ) ) AS progression_geometry + FROM qgep_od.reach + LEFT JOIN qgep_od.reach_point rp_to ON rp_to.obj_id = reach.fk_reach_point_to + LEFT JOIN qgep_od.wastewater_node wn_to ON rp_to.fk_wastewater_networkelement = wn_to.obj_id + WHERE + reach.fk_reach_point_to IS NOT NULL + AND + wn_to.obj_id IS NOT NULL + ) AS connectors + LEFT JOIN qgep_od.wastewater_networkelement ne ON ne.obj_id = connectors.obj_id + ) AS parts +WHERE GeometryType(progression_geometry) <> 'GEOMETRYCOLLECTION'; + + + + +REFRESH MATERIALIZED view qgep_od.vw_network_node; +REFRESH MATERIALIZED view qgep_od.vw_network_segment; + + + + +----------------------------------------------- +-- View: qgep_od.vw_qgep_reach and rules and triggers +----------------------------------------------- + +CREATE OR REPLACE VIEW qgep_od.vw_qgep_reach AS + +/* WITH active_maintenance_event AS ( + SELECT me.obj_id, me.identifier, me.active_zone, mews.fk_wastewater_structure FROM qgep_od.maintenance_event me + LEFT JOIN + qgep_od.re_maintenance_event_wastewater_structure mews ON mews.fk_maintenance_event = me.obj_id + WHERE active_zone IS NOT NULL +) */ + +SELECT re.obj_id, + re.clear_height AS clear_height, + re.material, + ch.usage_current AS ch_usage_current, + ch.function_hierarchic AS ch_function_hierarchic, + ws.status AS ws_status, + ws.fk_owner AS ws_fk_owner, + ch.function_hydraulic AS ch_function_hydraulic, + CASE WHEN pp.height_width_ratio IS NOT NULL THEN round(re.clear_height::numeric * pp.height_width_ratio)::smallint ELSE clear_height END AS width, + re.coefficient_of_friction, + re.elevation_determination, + re.horizontal_positioning, + re.inside_coating, + re.length_effective, + CASE WHEN rp_from.level > 0 AND rp_to.level > 0 THEN round((rp_from.level - rp_to.level)/re.length_effective*1000,1) ELSE NULL END AS _slope_per_mill, + re.progression_geometry, + re.reliner_material, + re.reliner_nominal_size, + re.relining_construction, + re.relining_kind, + re.ring_stiffness, + re.slope_building_plan, + re.wall_roughness, + re.fk_pipe_profile, + ne.identifier, + ne.remark, + ne.last_modification, + ne.fk_dataowner, + ne.fk_provider, + ne.fk_wastewater_structure, + ch.bedding_encasement AS ch_bedding_encasement, + ch.connection_type AS ch_connection_type, + ch.jetting_interval AS ch_jetting_interval, + ch.pipe_length AS ch_pipe_length, + ch.usage_planned AS ch_usage_planned, + ws.obj_id AS ws_obj_id, + ws.accessibility AS ws_accessibility, + ws.contract_section AS ws_contract_section, + ws.financing AS ws_financing, + ws.gross_costs AS ws_gross_costs, + ws.identifier AS ws_identifier, + ws.inspection_interval AS ws_inspection_interval, + ws.location_name AS ws_location_name, + ws.records AS ws_records, + ws.remark AS ws_remark, + ws.renovation_necessity AS ws_renovation_necessity, + ws.replacement_value AS ws_replacement_value, + ws.rv_base_year AS ws_rv_base_year, + ws.rv_construction_type AS ws_rv_construction_type, + ws.structure_condition AS ws_structure_condition, + ws.subsidies AS ws_subsidies, + ws.year_of_construction AS ws_year_of_construction, + ws.year_of_replacement AS ws_year_of_replacement, + ws.fk_operator AS ws_fk_operator, + rp_from.obj_id AS rp_from_obj_id, + rp_from.elevation_accuracy AS rp_from_elevation_accuracy, + rp_from.identifier AS rp_from_identifier, + rp_from.level AS rp_from_level, + rp_from.outlet_shape AS rp_from_outlet_shape, + rp_from.position_of_connection AS rp_from_position_of_connection, + rp_from.remark AS rp_from_remark, + rp_from.last_modification AS rp_from_last_modification, + rp_from.fk_dataowner AS rp_from_fk_dataowner, + rp_from.fk_provider AS rp_from_fk_provider, + rp_from.fk_wastewater_networkelement AS rp_from_fk_wastewater_networkelement, + rp_to.obj_id AS rp_to_obj_id, + rp_to.elevation_accuracy AS rp_to_elevation_accuracy, + rp_to.identifier AS rp_to_identifier, + rp_to.level AS rp_to_level, + rp_to.outlet_shape AS rp_to_outlet_shape, + rp_to.position_of_connection AS rp_to_position_of_connection, + rp_to.remark AS rp_to_remark, + rp_to.last_modification AS rp_to_last_modification, + rp_to.fk_dataowner AS rp_to_fk_dataowner, + rp_to.fk_provider AS rp_to_fk_provider, + rp_to.fk_wastewater_networkelement AS rp_to_fk_wastewater_networkelement + /* am.obj_id AS me_obj_id, + am.active_zone AS me_active_zone, + am.identifier AS me_identifier */ + FROM qgep_od.reach re + LEFT JOIN qgep_od.wastewater_networkelement ne ON ne.obj_id = re.obj_id + LEFT JOIN qgep_od.reach_point rp_from ON rp_from.obj_id = re.fk_reach_point_from + LEFT JOIN qgep_od.reach_point rp_to ON rp_to.obj_id = re.fk_reach_point_to + LEFT JOIN qgep_od.wastewater_structure ws ON ne.fk_wastewater_structure = ws.obj_id + LEFT JOIN qgep_od.channel ch ON ch.obj_id = ws.obj_id + LEFT JOIN qgep_od.pipe_profile pp ON re.fk_pipe_profile = pp.obj_id; + /* LEFT JOIN active_maintenance_event am ON am.fk_wastewater_structure = ch.obj_id; */ + +-- REACH INSERT +-- Trigger: vw_qgep_reach_on_insert() +-- Comment: triggerfunction need not anymore to force 2d +-- REACH INSERT +-- Function: vw_qgep_reach_insert() + + +CREATE OR REPLACE FUNCTION qgep_od.vw_qgep_reach_insert() + RETURNS trigger AS +$BODY$ +BEGIN + -- Synchronize geometry with level + NEW.progression_geometry = ST_ForceCurve(ST_SetPoint(ST_CurveToLine(NEW.progression_geometry),0, + ST_MakePoint(ST_X(ST_StartPoint(NEW.progression_geometry)),ST_Y(ST_StartPoint(NEW.progression_geometry)),COALESCE(NEW.rp_from_level,'NaN')))); + + NEW.progression_geometry = ST_ForceCurve(ST_SetPoint(ST_CurveToLine(NEW.progression_geometry),ST_NumPoints(NEW.progression_geometry)-1, + ST_MakePoint(ST_X(ST_EndPoint(NEW.progression_geometry)),ST_Y(ST_EndPoint(NEW.progression_geometry)),COALESCE(NEW.rp_to_level,'NaN')))); + + INSERT INTO qgep_od.reach_point( + obj_id + , elevation_accuracy + , identifier + , level + , outlet_shape + , position_of_connection + , remark + , situation_geometry + , last_modification + , fk_dataowner + , fk_provider + , fk_wastewater_networkelement + ) + VALUES ( + COALESCE(NEW.rp_from_obj_id,qgep_sys.generate_oid('qgep_od','reach_point')) -- obj_id + , NEW.rp_from_elevation_accuracy -- elevation_accuracy + , NEW.rp_from_identifier -- identifier + , NEW.rp_from_level -- level + , NEW.rp_from_outlet_shape -- outlet_shape + , NEW.rp_from_position_of_connection -- position_of_connection + , NEW.rp_from_remark -- remark + , ST_StartPoint(NEW.progression_geometry) -- situation_geometry + , NEW.rp_from_last_modification -- last_modification + , NEW.rp_from_fk_dataowner -- fk_dataowner + , NEW.rp_from_fk_provider -- fk_provider + , NEW.rp_from_fk_wastewater_networkelement -- fk_wastewater_networkelement + ) + RETURNING obj_id INTO NEW.rp_from_obj_id; + + + INSERT INTO qgep_od.reach_point( + obj_id + , elevation_accuracy + , identifier + , level + , outlet_shape + , position_of_connection + , remark + , situation_geometry + , last_modification + , fk_dataowner + , fk_provider + , fk_wastewater_networkelement + ) + VALUES ( + COALESCE(NEW.rp_to_obj_id,qgep_sys.generate_oid('qgep_od','reach_point')) -- obj_id + , NEW.rp_to_elevation_accuracy -- elevation_accuracy + , NEW.rp_to_identifier -- identifier + , NEW.rp_to_level -- level + , NEW.rp_to_outlet_shape -- outlet_shape + , NEW.rp_to_position_of_connection -- position_of_connection + , NEW.rp_to_remark -- remark + , ST_EndPoint(NEW.progression_geometry) -- situation_geometry + , NEW.rp_to_last_modification -- last_modification + , NEW.rp_to_fk_dataowner -- fk_dataowner + , NEW.rp_to_fk_provider -- fk_provider + , NEW.rp_to_fk_wastewater_networkelement -- fk_wastewater_networkelement + ) + RETURNING obj_id INTO NEW.rp_to_obj_id; + + INSERT INTO qgep_od.wastewater_structure ( + obj_id + , accessibility + , contract_section + -- , detail_geometry_geometry + , financing + , gross_costs + , identifier + , inspection_interval + , location_name + , records + , remark + , renovation_necessity + , replacement_value + , rv_base_year + , rv_construction_type + , status + , structure_condition + , subsidies + , year_of_construction + , year_of_replacement + -- , last_modification + -- , fk_dataowner + -- , fk_provider + , fk_owner + , fk_operator ) + + VALUES ( COALESCE(NEW.fk_wastewater_structure,qgep_sys.generate_oid('qgep_od','channel')) -- obj_id + , NEW.ws_accessibility + , NEW.ws_contract_section + -- , NEW.detail_geometry_geometry + , NEW.ws_financing + , NEW.ws_gross_costs + , NEW.ws_identifier + , NEW.ws_inspection_interval + , NEW.ws_location_name + , NEW.ws_records + , NEW.ws_remark + , NEW.ws_renovation_necessity + , NEW.ws_replacement_value + , NEW.ws_rv_base_year + , NEW.ws_rv_construction_type + , NEW.ws_status + , NEW.ws_structure_condition + , NEW.ws_subsidies + , NEW.ws_year_of_construction + , NEW.ws_year_of_replacement + -- , NEW.ws_last_modification + -- , NEW.fk_dataowner + -- , NEW.fk_provider + , NEW.ws_fk_owner + , NEW.ws_fk_operator + ) + RETURNING obj_id INTO NEW.fk_wastewater_structure; + + INSERT INTO qgep_od.channel( + obj_id + , bedding_encasement + , connection_type + , function_hierarchic + , function_hydraulic + , jetting_interval + , pipe_length + , usage_current + , usage_planned + ) + VALUES( + NEW.fk_wastewater_structure + , NEW.ch_bedding_encasement + , NEW.ch_connection_type + , NEW.ch_function_hierarchic + , NEW.ch_function_hydraulic + , NEW.ch_jetting_interval + , NEW.ch_pipe_length + , NEW.ch_usage_current + , NEW.ch_usage_planned + ); + + INSERT INTO qgep_od.wastewater_networkelement ( + obj_id + , identifier + , remark + , last_modification + , fk_dataowner + , fk_provider + , fk_wastewater_structure ) + VALUES ( COALESCE(NEW.obj_id,qgep_sys.generate_oid('qgep_od','reach')) -- obj_id + , NEW.identifier -- identifier + , NEW.remark -- remark + , NEW.last_modification -- last_modification + , NEW.fk_dataowner -- fk_dataowner + , NEW.fk_provider -- fk_provider + , NEW.fk_wastewater_structure -- fk_wastewater_structure + ) + RETURNING obj_id INTO NEW.obj_id; + + INSERT INTO qgep_od.reach ( + obj_id + , clear_height + , coefficient_of_friction + , elevation_determination + , horizontal_positioning + , inside_coating + , length_effective + , material + , progression_geometry + , reliner_material + , reliner_nominal_size + , relining_construction + , relining_kind + , ring_stiffness + , slope_building_plan + , wall_roughness + , fk_reach_point_from + , fk_reach_point_to + , fk_pipe_profile ) + VALUES( + NEW.obj_id -- obj_id + , NEW.clear_height + , NEW.coefficient_of_friction + , NEW.elevation_determination + , NEW.horizontal_positioning + , NEW.inside_coating + , NEW.length_effective + , NEW.material + , NEW.progression_geometry + , NEW.reliner_material + , NEW.reliner_nominal_size + , NEW.relining_construction + , NEW.relining_kind + , NEW.ring_stiffness + , NEW.slope_building_plan + , NEW.wall_roughness + , NEW.rp_from_obj_id + , NEW.rp_to_obj_id + , NEW.fk_pipe_profile); + + RETURN NEW; +END; $BODY$ + LANGUAGE plpgsql VOLATILE + COST 100; + +CREATE TRIGGER vw_qgep_reach_on_insert INSTEAD OF INSERT ON qgep_od.vw_qgep_reach + FOR EACH ROW EXECUTE PROCEDURE qgep_od.vw_qgep_reach_insert(); + +-- REACH UPDATE +-- Function: vw_qgep_reach_update() + +CREATE OR REPLACE FUNCTION qgep_od.vw_qgep_reach_on_update() + RETURNS trigger AS +$BODY$ +BEGIN + + -- Synchronize geometry with level + IF NEW.rp_from_level <> OLD.rp_from_level OR (NEW.rp_from_level IS NULL AND OLD.rp_from_level IS NOT NULL) OR (NEW.rp_from_level IS NOT NULL AND OLD.rp_from_level IS NULL) THEN + NEW.progression_geometry = ST_ForceCurve(ST_SetPoint(ST_CurveToLine(NEW.progression_geometry),0, + ST_MakePoint(ST_X(ST_StartPoint(NEW.progression_geometry)),ST_Y(ST_StartPoint(NEW.progression_geometry)),COALESCE(NEW.rp_from_level,'NaN')))); + ELSE + IF ST_Z(ST_StartPoint(NEW.progression_geometry)) <> ST_Z(ST_StartPoint(OLD.progression_geometry)) THEN + NEW.rp_from_level = NULLIF(ST_Z(ST_StartPoint(NEW.progression_geometry)),'NaN'); + END IF; + END IF; + + -- Synchronize geometry with level + IF NEW.rp_to_level <> OLD.rp_to_level OR (NEW.rp_to_level IS NULL AND OLD.rp_to_level IS NOT NULL) OR (NEW.rp_to_level IS NOT NULL AND OLD.rp_to_level IS NULL) THEN + NEW.progression_geometry = ST_ForceCurve(ST_SetPoint(ST_CurveToLine(NEW.progression_geometry),ST_NumPoints(NEW.progression_geometry)-1, + ST_MakePoint(ST_X(ST_EndPoint(NEW.progression_geometry)),ST_Y(ST_EndPoint(NEW.progression_geometry)),COALESCE(NEW.rp_to_level,'NaN')))); + ELSE + IF ST_Z(ST_EndPoint(NEW.progression_geometry)) <> ST_Z(ST_EndPoint(OLD.progression_geometry)) THEN + NEW.rp_to_level = NULLIF(ST_Z(ST_EndPoint(NEW.progression_geometry)),'NaN'); + END IF; + END IF; + + UPDATE qgep_od.reach_point + SET + elevation_accuracy = NEW.rp_from_elevation_accuracy + , identifier = NEW.rp_from_identifier + , level = NEW.rp_from_level + , outlet_shape = NEW.rp_from_outlet_shape + , position_of_connection = NEW.rp_from_position_of_connection + , remark = NEW.rp_from_remark + , situation_geometry = ST_StartPoint(NEW.progression_geometry) + , last_modification = NEW.rp_from_last_modification + , fk_dataowner = NEW.rp_from_fk_dataowner + , fk_provider = NEW.rp_from_fk_provider + , fk_wastewater_networkelement = NEW.rp_from_fk_wastewater_networkelement + WHERE obj_id = OLD.rp_from_obj_id; + + UPDATE qgep_od.reach_point + SET + elevation_accuracy = NEW.rp_to_elevation_accuracy + , identifier = NEW.rp_to_identifier + , level = NEW.rp_to_level + , outlet_shape = NEW.rp_to_outlet_shape + , position_of_connection = NEW.rp_to_position_of_connection + , remark = NEW.rp_to_remark + , situation_geometry = ST_EndPoint(NEW.progression_geometry) + , last_modification = NEW.rp_to_last_modification + , fk_dataowner = NEW.rp_to_fk_dataowner + , fk_provider = NEW.rp_to_fk_provider + , fk_wastewater_networkelement = NEW.rp_to_fk_wastewater_networkelement + WHERE obj_id = OLD.rp_to_obj_id; + + UPDATE qgep_od.channel + SET + bedding_encasement = NEW.ch_bedding_encasement + , connection_type = NEW.ch_connection_type + , function_hierarchic = NEW.ch_function_hierarchic + , function_hydraulic = NEW.ch_function_hydraulic + , jetting_interval = NEW.ch_jetting_interval + , pipe_length = NEW.ch_pipe_length + , usage_current = NEW.ch_usage_current + , usage_planned = NEW.ch_usage_planned + WHERE obj_id = OLD.fk_wastewater_structure; + + UPDATE qgep_od.wastewater_structure + SET + accessibility = NEW.ws_accessibility + , contract_section = NEW.ws_contract_section + -- , detail_geometry_geometry = NEW.detail_geometry_geometry + , financing = NEW.ws_financing + , gross_costs = NEW.ws_gross_costs + , identifier = NEW.ws_identifier + , inspection_interval = NEW.ws_inspection_interval + , location_name = NEW.ws_location_name + , records = NEW.ws_records + , remark = NEW.ws_remark + , renovation_necessity = NEW.ws_renovation_necessity + , replacement_value = NEW.ws_replacement_value + , rv_base_year = NEW.ws_rv_base_year + , rv_construction_type = NEW.ws_rv_construction_type + , status = NEW.ws_status + , structure_condition = NEW.ws_structure_condition + , subsidies = NEW.ws_subsidies + , year_of_construction = NEW.ws_year_of_construction + , year_of_replacement = NEW.ws_year_of_replacement + , fk_dataowner = NEW.fk_dataowner + , fk_provider = NEW.fk_provider + , last_modification = NEW.last_modification + , fk_owner = NEW.ws_fk_owner + , fk_operator = NEW.ws_fk_operator + WHERE obj_id = OLD.fk_wastewater_structure; + + + UPDATE qgep_od.wastewater_networkelement + SET + identifier = NEW.identifier + , remark = NEW.remark + , last_modification = NEW.last_modification + , fk_dataowner = NEW.fk_dataowner + , fk_provider = NEW.fk_provider + , fk_wastewater_structure = NEW.fk_wastewater_structure + WHERE obj_id = OLD.obj_id; + + UPDATE qgep_od.reach + SET clear_height = NEW.clear_height + , coefficient_of_friction = NEW.coefficient_of_friction + , elevation_determination = NEW.elevation_determination + , horizontal_positioning = NEW.horizontal_positioning + , inside_coating = NEW.inside_coating + , length_effective = NEW.length_effective + , material = NEW.material + , progression_geometry = NEW.progression_geometry + , reliner_material = NEW.reliner_material + , reliner_nominal_size = NEW.reliner_nominal_size + , relining_construction = NEW.relining_construction + , relining_kind = NEW.relining_kind + , ring_stiffness = NEW.ring_stiffness + , slope_building_plan = NEW.slope_building_plan + , wall_roughness = NEW.wall_roughness + , fk_pipe_profile = NEW.fk_pipe_profile + WHERE obj_id = OLD.obj_id; + + RETURN NEW; +END; $BODY$ + LANGUAGE plpgsql VOLATILE; + +CREATE TRIGGER vw_qgep_reach_on_update + INSTEAD OF UPDATE + ON qgep_od.vw_qgep_reach + FOR EACH ROW + EXECUTE PROCEDURE qgep_od.vw_qgep_reach_on_update(); + +-- REACH DELETE +-- Rule: vw_qgep_reach_on_delete() + +CREATE OR REPLACE RULE vw_qgep_reach_on_delete AS ON DELETE TO qgep_od.vw_qgep_reach DO INSTEAD ( + DELETE FROM qgep_od.reach WHERE obj_id = OLD.obj_id; +); + +--missing: delete also connected wastewater_structure (and subclass channel or other), structure_parts, re_maintenance_events + +ALTER VIEW qgep_od.vw_qgep_reach ALTER obj_id SET DEFAULT qgep_sys.generate_oid('qgep_od','reach'); + +ALTER VIEW qgep_od.vw_qgep_reach ALTER rp_from_obj_id SET DEFAULT qgep_sys.generate_oid('qgep_od','reach_point'); +ALTER VIEW qgep_od.vw_qgep_reach ALTER rp_to_obj_id SET DEFAULT qgep_sys.generate_oid('qgep_od','reach_point'); +ALTER VIEW qgep_od.vw_qgep_reach ALTER fk_wastewater_structure SET DEFAULT qgep_sys.generate_oid('qgep_od','channel'); + + + +----------------------------------------------- +-- View: qgep_od.vw_change_points +----------------------------------------------- +CREATE VIEW qgep_od.vw_change_points AS +SELECT + rp_to.obj_id, + rp_to.situation_geometry::geometry(POINTZ, %(SRID)s) AS geom, + re.material <> re_next.material AS change_in_material, + re.clear_height <> re_next.clear_height AS change_in_clear_height, + (rp_from.level - rp_to.level) / re.length_effective - (rp_next_from.level - rp_next_to.level) / re_next.length_effective AS change_in_slope +FROM qgep_od.reach re +LEFT JOIN qgep_od.reach_point rp_to ON rp_to.obj_id = re.fk_reach_point_to +LEFT JOIN qgep_od.reach_point rp_from ON rp_from.obj_id = re.fk_reach_point_from +LEFT JOIN qgep_od.reach re_next ON rp_to.fk_wastewater_networkelement = re_next.obj_id +LEFT JOIN qgep_od.reach_point rp_next_to ON rp_next_to.obj_id = re_next.fk_reach_point_to +LEFT JOIN qgep_od.reach_point rp_next_from ON rp_next_from.obj_id = re_next.fk_reach_point_from +LEFT JOIN qgep_od.wastewater_networkelement ne ON re.obj_id = ne.obj_id +LEFT JOIN qgep_od.wastewater_networkelement ne_next ON re_next.obj_id = ne_next.obj_id +WHERE ne_next.fk_wastewater_structure = ne.fk_wastewater_structure; + + + + +----------------------------------------------- +----------------------------------------------- +-- RECREATE DEPENDENCIES OF qgep_od.wastewaternode +----------------------------------------------- +----------------------------------------------- +----------------------------------------------- +-- View: qgep_od.vw_qgep_overflow and triggers +----------------------------------------------- +-- Comment: this is originally created by python function and not by script - hope this works: + +CREATE OR REPLACE VIEW qgep_od.vw_qgep_overflow AS + SELECT + CASE + WHEN leapingweir.obj_id IS NOT NULL THEN 'leapingweir'::qgep_od.overflow_type + WHEN prank_weir.obj_id IS NOT NULL THEN 'prank_weir'::qgep_od.overflow_type + WHEN pump.obj_id IS NOT NULL THEN 'pump'::qgep_od.overflow_type + ELSE 'overflow'::qgep_od.overflow_type + END AS overflow_type, + overflow.obj_id, + overflow.actuation, + overflow.adjustability, + overflow.brand, + overflow.control, + overflow.discharge_point, + overflow.function, + overflow.gross_costs, + overflow.identifier, + overflow.qon_dim, + overflow.remark, + overflow.signal_transmission, + overflow.subsidies, + overflow.last_modification, + overflow.fk_dataowner, + overflow.fk_provider, + overflow.fk_wastewater_node, + overflow.fk_overflow_to, + overflow.fk_overflow_characteristic, + overflow.fk_control_center, + st_makeline(n1.situation_geometry, n2.situation_geometry)::geometry(LineString,%(SRID)s) AS geometry, + leapingweir.length, + leapingweir.opening_shape, + leapingweir.width, + prank_weir.hydraulic_overflow_length, + prank_weir.level_max, + prank_weir.level_min, + prank_weir.weir_edge, + prank_weir.weir_kind, + pump.contruction_type, + pump.operating_point, + pump.placement_of_actuation, + pump.placement_of_pump, + pump.pump_flow_max_single, + pump.pump_flow_min_single, + pump.start_level, + pump.stop_level, + pump.usage_current + FROM qgep_od.overflow overflow + LEFT JOIN qgep_od.leapingweir leapingweir ON overflow.obj_id::text = leapingweir.obj_id::text + LEFT JOIN qgep_od.prank_weir prank_weir ON overflow.obj_id::text = prank_weir.obj_id::text + LEFT JOIN qgep_od.pump pump ON overflow.obj_id::text = pump.obj_id::text + LEFT JOIN qgep_od.wastewater_node n1 ON overflow.fk_wastewater_node::text = n1.obj_id::text + LEFT JOIN qgep_od.wastewater_node n2 ON overflow.fk_overflow_to::text = n2.obj_id::text; + +ALTER TABLE qgep_od.vw_qgep_overflow + OWNER TO postgres; + +-- Trigger: tr_vw_qgep_overflow_delete on qgep_od.vw_qgep_overflow +CREATE TRIGGER tr_vw_qgep_overflow_delete + INSTEAD OF DELETE + ON qgep_od.vw_qgep_overflow + FOR EACH ROW + EXECUTE PROCEDURE qgep_od.ft_vw_qgep_overflow_delete(); + +-- Trigger: tr_vw_qgep_overflow_insert on qgep_od.vw_qgep_overflow +CREATE TRIGGER tr_vw_qgep_overflow_insert + INSTEAD OF INSERT + ON qgep_od.vw_qgep_overflow + FOR EACH ROW + EXECUTE PROCEDURE qgep_od.ft_vw_qgep_overflow_insert(); + +-- Trigger: tr_vw_qgep_overflow_update on qgep_od.vw_qgep_overflow +CREATE TRIGGER tr_vw_qgep_overflow_update + INSTEAD OF UPDATE + ON qgep_od.vw_qgep_overflow + FOR EACH ROW + EXECUTE PROCEDURE qgep_od.ft_vw_qgep_overflow_update(); + + + +----------------------------------------------- +-- View: qgep_od.vw_catchment_area_connections +----------------------------------------------- +CREATE VIEW qgep_od.vw_catchment_area_connections AS +SELECT + +ca.obj_id, +ST_MakeLine(ST_Centroid(ST_CurveToLine(perimeter_geometry)), +wn_rw_current.situation_geometry)::geometry( LineString, %(SRID)s ) AS connection_rw_current_geometry, +ST_MakeLine(ST_Centroid(ST_CurveToLine(perimeter_geometry)), +wn_ww_current.situation_geometry)::geometry( LineString, %(SRID)s ) AS connection_ww_current_geometry + +FROM qgep_od.catchment_area ca +LEFT JOIN qgep_od.wastewater_node wn_rw_current +ON ca.fk_wastewater_networkelement_rw_current = wn_rw_current.obj_id +LEFT JOIN qgep_od.wastewater_node wn_ww_current +ON ca.fk_wastewater_networkelement_ww_current = wn_ww_current.obj_id; + + + +----------------------------------------------- +-- View: qgep_od.vw_wastewater_node +----------------------------------------------- +CREATE OR REPLACE VIEW qgep_od.vw_wastewater_node AS + +SELECT + WN.obj_id + , WN.backflow_level + , WN.bottom_level + , WN.situation_geometry + , WE.identifier + , WE.remark + , WE.fk_dataowner + , WE.fk_provider + , WE.last_modification + , WE.fk_wastewater_structure + FROM qgep_od.wastewater_node WN + LEFT JOIN qgep_od.wastewater_networkelement WE + ON WE.obj_id = WN.obj_id; + + +ALTER TABLE qgep_od.vw_wastewater_node ALTER COLUMN obj_id SET DEFAULT qgep_sys.generate_oid('qgep_od'::text, 'wastewater_node'::text); + +-- Comment: only trigger - function is still existing +CREATE TRIGGER vw_wastewater_node_ON_INSERT INSTEAD OF INSERT ON qgep_od.vw_wastewater_node + FOR EACH ROW EXECUTE PROCEDURE qgep_od.vw_wastewater_node_insert(); + +-- Rule: vw_wastewater_node_ON_UPDATE() +CREATE OR REPLACE RULE vw_wastewater_node_ON_UPDATE AS ON UPDATE TO qgep_od.vw_wastewater_node DO INSTEAD ( +UPDATE qgep_od.wastewater_node + SET + backflow_level = NEW.backflow_level + , bottom_level = NEW.bottom_level + , situation_geometry = NEW.situation_geometry + WHERE obj_id = OLD.obj_id; + +UPDATE qgep_od.wastewater_networkelement + SET + identifier = NEW.identifier + , remark = NEW.remark + , fk_dataowner = NEW.fk_dataowner + , fk_provider = NEW.fk_provider + , last_modification = NEW.last_modification + , fk_wastewater_structure = NEW.fk_wastewater_structure + WHERE obj_id = OLD.obj_id; +); + +-- Rule: vw_wastewater_node_ON_DELETE () +CREATE OR REPLACE RULE vw_wastewater_node_ON_DELETE AS ON DELETE TO qgep_od.vw_wastewater_node DO INSTEAD ( + DELETE FROM qgep_od.wastewater_node WHERE obj_id = OLD.obj_id; + DELETE FROM qgep_od.wastewater_networkelement WHERE obj_id = OLD.obj_id; +); + + + +----------------------------------------------- +-- qgep_od.vw_qgep_wastewater_structure +----------------------------------------------- +CREATE OR REPLACE VIEW qgep_od.vw_qgep_wastewater_structure AS + SELECT + ws.identifier as identifier, + + CASE + WHEN ma.obj_id IS NOT NULL THEN 'manhole' + WHEN ss.obj_id IS NOT NULL THEN 'special_structure' + WHEN dp.obj_id IS NOT NULL THEN 'discharge_point' + WHEN ii.obj_id IS NOT NULL THEN 'infiltration_installation' + ELSE 'unknown' + END AS ws_type, + ma.function AS ma_function, + ss.function as ss_function, + ws.fk_owner, + ws.status, + + ws.accessibility, + ws.contract_section, + ws.financing, + ws.gross_costs, + ws.inspection_interval, + ws.location_name, + ws.records, + ws.remark, + ws.renovation_necessity, + ws.replacement_value, + ws.rv_base_year, + ws.rv_construction_type, + ws.structure_condition, + ws.subsidies, + ws.year_of_construction, + ws.year_of_replacement, + ws.last_modification, + ws.fk_operator, + ws.fk_dataowner, + ws.fk_provider, + ws._depth, + ws.obj_id, + + main_co_sp.identifier AS co_identifier, + main_co.brand AS co_brand, + main_co.cover_shape AS co_shape, + main_co.diameter AS co_diameter, + main_co.fastening AS co_fastening, + main_co.level AS co_level, + main_co.material AS co_material, + main_co.positional_accuracy AS co_positional_accuracy, + aggregated_wastewater_structure.situation_geometry, + main_co.sludge_bucket AS co_sludge_bucket, + main_co.venting AS co_venting, + main_co_sp.remark AS co_remark, + main_co_sp.renovation_demand AS co_renovation_demand, + main_co.obj_id AS co_obj_id, + + ma.material AS ma_material, + ma.surface_inflow AS ma_surface_inflow, + ma.dimension1 AS ma_dimension1, + ma.dimension2 AS ma_dimension2, + ma._orientation AS ma_orientation, + + ss.bypass AS ss_bypass, + ss.emergency_spillway AS ss_emergency_spillway, + ss.stormwater_tank_arrangement AS ss_stormwater_tank_arrangement, + ss.upper_elevation AS ss_upper_elevation, + + ii.absorption_capacity AS ii_absorption_capacity, + ii.defects AS ii_defects, + ii.dimension1 AS ii_dimension1, + ii.dimension2 AS ii_dimension2, + ii.distance_to_aquifer AS ii_distance_to_aquifer, + ii.effective_area AS ii_effective_area, + ii.emergency_spillway AS ii_emergency_spillway, + ii.kind AS ii_kind, + ii.labeling AS ii_labeling, + ii.seepage_utilization AS ii_seepage_utilization, + ii.upper_elevation AS ii_upper_elevation, + ii.vehicle_access AS ii_vehicle_access, + ii.watertightness AS ii_watertightness, + + dp.highwater_level AS dp_highwater_level, + dp.relevance AS dp_relevance, + dp.terrain_level AS dp_terrain_level, + dp.upper_elevation AS dp_upper_elevation, + dp.waterlevel_hydraulic AS dp_waterlevel_hydraulic, + + wn.identifier AS wn_identifier, + wn.obj_id AS wn_obj_id, + wn.backflow_level AS wn_backflow_level, + wn.bottom_level AS wn_bottom_level, + -- wn.situation_geometry , + wn.remark AS wn_remark, + wn.last_modification AS wn_last_modification, + wn.fk_dataowner AS wn_fk_dataowner, + wn.fk_provider AS wn_fk_provider, + + ws._label, + ws._usage_current AS _channel_usage_current, + ws._function_hierarchic AS _channel_function_hierarchic + + FROM ( + SELECT ws.obj_id, + ST_Collect(co.situation_geometry)::geometry(MULTIPOINTZ, %(SRID)s) AS situation_geometry, + CASE WHEN COUNT(wn.obj_id) = 1 THEN MIN(wn.obj_id) ELSE NULL END AS wn_obj_id + FROM qgep_od.wastewater_structure ws + FULL OUTER JOIN qgep_od.structure_part sp ON sp.fk_wastewater_structure = ws.obj_id + LEFT JOIN qgep_od.cover co ON co.obj_id = sp.obj_id + RIGHT JOIN qgep_od.wastewater_networkelement ne ON ne.fk_wastewater_structure = ws.obj_id + RIGHT JOIN qgep_od.wastewater_node wn ON wn.obj_id = ne.obj_id + GROUP BY ws.obj_id + ) aggregated_wastewater_structure + LEFT JOIN qgep_od.wastewater_structure ws ON ws.obj_id = aggregated_wastewater_structure.obj_id + LEFT JOIN qgep_od.cover main_co ON main_co.obj_id = ws.fk_main_cover + LEFT JOIN qgep_od.structure_part main_co_sp ON main_co_sp.obj_id = ws.fk_main_cover + LEFT JOIN qgep_od.manhole ma ON ma.obj_id = ws.obj_id + LEFT JOIN qgep_od.special_structure ss ON ss.obj_id = ws.obj_id + LEFT JOIN qgep_od.discharge_point dp ON dp.obj_id = ws.obj_id + LEFT JOIN qgep_od.infiltration_installation ii ON ii.obj_id = ws.obj_id + LEFT JOIN qgep_od.vw_wastewater_node wn ON wn.obj_id = aggregated_wastewater_structure.wn_obj_id; + +-- Comment: only trigger - function is still existing +CREATE TRIGGER vw_qgep_wastewater_structure_ON_INSERT INSTEAD OF INSERT ON qgep_od.vw_qgep_wastewater_structure + FOR EACH ROW EXECUTE PROCEDURE qgep_od.vw_qgep_wastewater_structure_INSERT(); + +-- Comment: only trigger - function is still existing +CREATE TRIGGER vw_qgep_wastewater_structure_ON_UPDATE INSTEAD OF UPDATE ON qgep_od.vw_qgep_wastewater_structure + FOR EACH ROW EXECUTE PROCEDURE qgep_od.vw_qgep_wastewater_structure_UPDATE(); + +-- Comment: only trigger - function is still existing +CREATE TRIGGER vw_qgep_wastewater_structure_ON_DELETE INSTEAD OF DELETE ON qgep_od.vw_qgep_wastewater_structure + FOR EACH ROW EXECUTE PROCEDURE qgep_od.vw_qgep_wastewater_structure_DELETE(); + +ALTER VIEW qgep_od.vw_qgep_wastewater_structure ALTER obj_id SET DEFAULT qgep_sys.generate_oid('qgep_od','wastewater_structure'); +ALTER VIEW qgep_od.vw_qgep_wastewater_structure ALTER co_obj_id SET DEFAULT qgep_sys.generate_oid('qgep_od','structure_part'); + + + +----------------------------------------------- +-- qgep_import.vw_manhole +----------------------------------------------- + +CREATE OR REPLACE VIEW qgep_import.vw_manhole AS + SELECT DISTINCT ON (ws.obj_id) ws.obj_id, + ws.identifier, + (st_dump(ws.situation_geometry)).geom::geometry(POINTZ,%(SRID)s) AS situation_geometry, + ws.co_shape, + ws.co_diameter, + ws.co_material, + ws.co_positional_accuracy, + ws.co_level, + ws._depth::numeric(6, 3) AS _depth, + ws._channel_usage_current, + ws.ma_material, + ws.ma_dimension1, + ws.ma_dimension2, + ws.ws_type, + ws.ma_function, + ws.ss_function, + ws.remark, + ws.wn_bottom_level, + NULL::text AS photo1, + NULL::text AS photo2, + NULL::smallint AS inlet_3_material, + NULL::integer AS inlet_3_clear_height, + NULL::numeric(7, 3) AS inlet_3_depth_m, + NULL::smallint AS inlet_4_material, + NULL::integer AS inlet_4_clear_height, + NULL::numeric(7, 3) AS inlet_4_depth_m, + NULL::smallint AS inlet_5_material, + NULL::integer AS inlet_5_clear_height, + NULL::numeric(7, 3) AS inlet_5_depth_m, + NULL::smallint AS inlet_6_material, + NULL::integer AS inlet_6_clear_height, + NULL::numeric(7, 3) AS inlet_6_depth_m, + NULL::smallint AS inlet_7_material, + NULL::integer AS inlet_7_clear_height, + NULL::numeric(7, 3) AS inlet_7_depth_m, + NULL::smallint AS outlet_1_material, + NULL::integer AS outlet_1_clear_height, + NULL::numeric(7, 3) AS outlet_1_depth_m, + NULL::smallint AS outlet_2_material, + NULL::integer AS outlet_2_clear_height, + NULL::numeric(7, 3) AS outlet_2_depth_m, + FALSE::boolean AS verified, + (CASE WHEN EXISTS ( SELECT TRUE FROM qgep_import.manhole_quarantine q WHERE q.obj_id = ws.obj_id ) + THEN TRUE + ELSE FALSE + END) AS in_quarantine, + FALSE::boolean AS deleted + + FROM qgep_od.vw_qgep_wastewater_structure ws; + +-- Comment: triggerfunction has to be rewritten because of Z coordinate +CREATE OR REPLACE FUNCTION qgep_import.manhole_quarantine_try_structure_update() RETURNS trigger AS $BODY$ +DECLARE + multi_situation_geometry geometry(MULTIPOINTZ,%(SRID)s); +BEGIN + multi_situation_geometry = st_collect(NEW.situation_geometry)::geometry(MULTIPOINTZ,%(SRID)s); + + -- in case there is a depth, but no refercing value - it should stay in quarantene + IF( NEW._depth IS NOT NULL AND NEW.co_level IS NULL AND NEW.wn_bottom_level IS NULL ) THEN + RAISE EXCEPTION 'No referencing value for calculation with depth'; + END IF; + + -- qgep_od.wastewater_structure + IF( SELECT TRUE FROM qgep_od.vw_qgep_wastewater_structure WHERE obj_id = NEW.obj_id ) THEN + UPDATE qgep_od.vw_qgep_wastewater_structure SET + identifier = NEW.identifier, + situation_geometry = multi_situation_geometry, + co_shape = NEW.co_shape, + co_diameter = NEW.co_diameter, + co_material = NEW.co_material, + co_positional_accuracy = NEW.co_positional_accuracy, + co_level = + (CASE WHEN NEW.co_level IS NULL AND NEW.wn_bottom_level IS NOT NULL AND NEW._depth IS NOT NULL + THEN NEW.wn_bottom_level + NEW._depth + ELSE NEW.co_level + END), + _depth = NEW._depth, + _channel_usage_current = NEW._channel_usage_current, + ma_material = NEW.ma_material, + ma_dimension1 = NEW.ma_dimension1, + ma_dimension2 = NEW.ma_dimension2, + ws_type = NEW.ws_type, + ma_function = NEW.ma_function, + ss_function = NEW.ss_function, + remark = NEW.remark, + wn_bottom_level = + (CASE WHEN NEW.wn_bottom_level IS NULL AND NEW.co_level IS NOT NULL AND NEW._depth IS NOT NULL + THEN NEW.co_level - NEW._depth + ELSE NEW.wn_bottom_level + END) + WHERE obj_id = NEW.obj_id; + RAISE NOTICE 'Updated row in qgep_od.vw_qgep_wastewater_structure'; + ELSE + INSERT INTO qgep_od.vw_qgep_wastewater_structure + ( + obj_id, + identifier, + situation_geometry, + co_shape, + co_diameter, + co_material, + co_positional_accuracy, + co_level, + _depth, + _channel_usage_current, + ma_material, + ma_dimension1, + ma_dimension2, + ws_type, + ma_function, + ss_function, + remark, + wn_bottom_level + ) + VALUES + ( + NEW.obj_id, + NEW.identifier, + multi_situation_geometry, + NEW.co_shape, + NEW.co_diameter, + NEW.co_material, + NEW.co_positional_accuracy, + (CASE WHEN NEW.co_level IS NULL AND NEW.wn_bottom_level IS NOT NULL AND NEW._depth IS NOT NULL + THEN NEW.wn_bottom_level + NEW._depth + ELSE NEW.co_level + END), + NEW._depth, + NEW._channel_usage_current, + NEW.ma_material, + NEW.ma_dimension1, + NEW.ma_dimension2, + NEW.ws_type, + NEW.ma_function, + NEW.ss_function, + NEW.remark, + (CASE WHEN NEW.wn_bottom_level IS NULL AND NEW.co_level IS NOT NULL AND NEW._depth IS NOT NULL + THEN NEW.co_level - NEW._depth + ELSE NEW.wn_bottom_level + END) + ); + RAISE NOTICE 'Inserted row in qgep_od.vw_qgep_wastewater_structure'; + END IF; + + -- photo1 insert + IF (NEW.photo1 IS NOT NULL) THEN + INSERT INTO qgep_od.file + ( + object, + identifier + ) + VALUES + ( + NEW.obj_id, + NEW.photo1 + ); + RAISE NOTICE 'Inserted row in qgep_od.file'; + END IF; + + -- photo2 insert + IF (NEW.photo2 IS NOT NULL) THEN + INSERT INTO qgep_od.file + ( + object, + identifier + ) + VALUES + ( + NEW.obj_id, + NEW.photo2 + ); + RAISE NOTICE 'Inserted row in qgep_od.file'; + END IF; + + -- set structure okay + UPDATE qgep_import.manhole_quarantine + SET structure_okay = true + WHERE quarantine_serial = NEW.quarantine_serial; + RETURN NEW; + + -- catch + EXCEPTION WHEN OTHERS THEN + RAISE NOTICE 'EXCEPTION: %%', SQLERRM; + RETURN NEW; +END; $BODY$ +LANGUAGE plpgsql; + +CREATE TRIGGER on_mutation_make_insert_or_delete + INSTEAD OF INSERT OR UPDATE + ON qgep_import.vw_manhole + FOR EACH ROW + EXECUTE PROCEDURE qgep_import.vw_manhole_insert_into_quarantine_or_delete(); + + + +----------------------------------------------- +----------------------------------------------- +-- RECREATE DEPENDENCIES OF qgep_od.cover +----------------------------------------------- +----------------------------------------------- +-- View: qgep_od.vw_cover +----------------------------------------------- +CREATE OR REPLACE VIEW qgep_od.vw_cover AS + +SELECT + CO.obj_id + , CO.brand + , CO.cover_shape + , CO.diameter + , CO.fastening + , CO.level + , CO.material + , CO.positional_accuracy + , CO.situation_geometry + , CO.sludge_bucket + , CO.venting + , SP.identifier + , SP.remark + , SP.renovation_demand + , SP.fk_dataowner + , SP.fk_provider + , SP.last_modification + , SP.fk_wastewater_structure + FROM qgep_od.cover CO + LEFT JOIN qgep_od.structure_part SP + ON SP.obj_id = CO.obj_id; + +-- Comment: only trigger - function is still existing +CREATE TRIGGER vw_cover_ON_INSERT INSTEAD OF INSERT ON qgep_od.vw_cover + FOR EACH ROW EXECUTE PROCEDURE qgep_od.vw_cover_insert(); + +-- Rule: vw_cover_ON_UPDATE() +CREATE OR REPLACE RULE vw_cover_ON_UPDATE AS ON UPDATE TO qgep_od.vw_cover DO INSTEAD ( +UPDATE qgep_od.cover + SET + brand = NEW.brand + , cover_shape = NEW.cover_shape + , diameter = NEW.diameter + , fastening = NEW.fastening + , level = NEW.level + , material = NEW.material + , positional_accuracy = NEW.positional_accuracy + , situation_geometry = NEW.situation_geometry + , sludge_bucket = NEW.sludge_bucket + , venting = NEW.venting + WHERE obj_id = OLD.obj_id; + +UPDATE qgep_od.structure_part + SET + identifier = NEW.identifier + , remark = NEW.remark + , renovation_demand = NEW.renovation_demand + , fk_dataowner = NEW.fk_dataowner + , fk_provider = NEW.fk_provider + , last_modification = NEW.last_modification + , fk_wastewater_structure = NEW.fk_wastewater_structure + WHERE obj_id = OLD.obj_id; +); + +-- Rule: vw_cover_ON_DELETE () +CREATE OR REPLACE RULE vw_cover_ON_DELETE AS ON DELETE TO qgep_od.vw_cover DO INSTEAD ( + DELETE FROM qgep_od.cover WHERE obj_id = OLD.obj_id; + DELETE FROM qgep_od.structure_part WHERE obj_id = OLD.obj_id; +); + + +----------------------------------------------- +----------------------------------------------- +-- Synchronize GEOMETRY with bottom_level qgep_od.wastewater_node +----------------------------------------------- +----------------------------------------------- + +CREATE OR REPLACE FUNCTION qgep_od.synchronize_level_with_altitude_on_wastewater_node() + RETURNS trigger AS +$BODY$ +BEGIN + CASE + WHEN TG_OP = 'INSERT' THEN + NEW.situation_geometry = ST_SetSRID( ST_MakePoint( ST_X(NEW.situation_geometry), ST_Y(NEW.situation_geometry), COALESCE(NEW.bottom_level,'NaN') ), %(SRID)s); + WHEN TG_OP = 'UPDATE' THEN + IF NEW.bottom_level <> OLD.bottom_level OR (NEW.bottom_level IS NULL AND OLD.bottom_level IS NOT NULL) OR (NEW.bottom_level IS NOT NULL AND OLD.bottom_level IS NULL) THEN + NEW.situation_geometry = ST_SetSRID( ST_MakePoint( ST_X(NEW.situation_geometry), ST_Y(NEW.situation_geometry), COALESCE(NEW.bottom_level,'NaN') ), %(SRID)s); + ELSE + IF ST_Z(NEW.situation_geometry) <> ST_Z(OLD.situation_geometry) THEN + NEW.bottom_level = NULLIF(ST_Z(NEW.situation_geometry),'NaN'); + END IF; + END IF; + END CASE; + + RETURN NEW; +END; $BODY$ + LANGUAGE plpgsql VOLATILE; + +DROP TRIGGER IF EXISTS synchronize_level_with_altitude ON qgep_od.wastewater_node; + +CREATE TRIGGER synchronize_level_with_altitude + BEFORE INSERT OR UPDATE + ON qgep_od.wastewater_node + FOR EACH ROW + EXECUTE PROCEDURE qgep_od.synchronize_level_with_altitude_on_wastewater_node(); + + +----------------------------------------------- +----------------------------------------------- +-- Synchronize GEOMETRY with level qgep_od.cover +----------------------------------------------- +----------------------------------------------- + +CREATE OR REPLACE FUNCTION qgep_od.synchronize_level_with_altitude_on_cover() + RETURNS trigger AS +$BODY$ +BEGIN + CASE + WHEN TG_OP = 'INSERT' THEN + NEW.situation_geometry = ST_SetSRID( ST_MakePoint( ST_X(NEW.situation_geometry), ST_Y(NEW.situation_geometry), COALESCE(NEW.level,'NaN') ), %(SRID)s); + WHEN TG_OP = 'UPDATE' THEN + IF NEW.level <> OLD.level OR (NEW.level IS NULL AND OLD.level IS NOT NULL) OR (NEW.level IS NOT NULL AND OLD.level IS NULL) THEN + NEW.situation_geometry = ST_SetSRID( ST_MakePoint( ST_X(NEW.situation_geometry), ST_Y(NEW.situation_geometry), COALESCE(NEW.level,'NaN') ), %(SRID)s); + ELSE + IF ST_Z(NEW.situation_geometry) <> ST_Z(OLD.situation_geometry) THEN + NEW.level = NULLIF(ST_Z(NEW.situation_geometry),'NaN'); + END IF; + END IF; + END CASE; + + RETURN NEW; +END; $BODY$ + LANGUAGE plpgsql VOLATILE; + +DROP TRIGGER IF EXISTS synchronize_level_with_altitude ON qgep_od.cover; + +CREATE TRIGGER synchronize_level_with_altitude + BEFORE INSERT OR UPDATE + ON qgep_od.cover + FOR EACH ROW + EXECUTE PROCEDURE qgep_od.synchronize_level_with_altitude_on_cover(); diff --git a/scripts/db_setup.sh b/scripts/db_setup.sh index c13efc9a..5dbfbe1f 100755 --- a/scripts/db_setup.sh +++ b/scripts/db_setup.sh @@ -110,3 +110,5 @@ VERSION=$(cat ${DIR}/system/CURRENT_VERSION.txt) pum baseline -p ${PGSERVICE} -t qgep_sys.pum_info -d ${DIR}/delta/ -b ${VERSION} psql "service=${PGSERVICE}" -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/13_import.sql + +psql "service=${PGSERVICE}" -v ON_ERROR_STOP=1 -v SRID=$SRID -f ${DIR}/14_geometry_functions.sql diff --git a/test/test_geometry.py b/test/test_geometry.py new file mode 100644 index 00000000..8e3eacdd --- /dev/null +++ b/test/test_geometry.py @@ -0,0 +1,590 @@ +import unittest +import os + +import psycopg2 +import psycopg2.extras +import decimal +import copy + +from utils import DbTestBase + +class TestViews(unittest.TestCase, DbTestBase): + + @classmethod + def tearDownClass(cls): + cls.conn.rollback() + + @classmethod + def setUpClass(cls): + pgservice=os.environ.get('PGSERVICE') + if not pgservice: + pgservice='pg_qgep' + cls.conn = psycopg2.connect("service={service}".format(service=pgservice)) + + def test_vw_qgep_reach_geometry_insert(self): + # 1. insert geometry with Z and no rp_from_level and no rp_to_level + # INSERT INTO qgep_od.vw_qgep_reach (progression_geometry, rp_from_obj_id, rp_to_obj_id) VALUES (ST_SetSRID(ST_GeomFromText('COMPOUNDCURVE Z ((1 2 3,4 5 6,7 8 9))'), 2056), 'BBB 1337_0001', 'CCC 1337_0001' ); + row = { + 'progression_geometry': '01090000A00808000001000000010200008003000000000000000000F03F000000000000004000000000000008400000000000001040000000000000144000000000000018400000000000001C4000000000000020400000000000002240', + 'rp_from_obj_id': 'BBB 1337_0001', + 'rp_to_obj_id': 'CCC 1337_0001' + } + expected_row = copy.deepcopy(row) + # vw_qgep_reach has the geometry but NaN as Z on start_point and NaN as Z on end_point: SELECT ST_SetSRID( ST_ForceCurve(ST_MakeLine(ARRAY[ST_MakePoint(1,2,'NaN'), ST_MakePoint(4,5,6), ST_MakePoint(7,8,'NaN')])), 2056) + expected_row['progression_geometry'] = '01090000A00808000001000000010200008003000000000000000000F03F0000000000000040000000000000F87F0000000000001040000000000000144000000000000018400000000000001C400000000000002040000000000000F87F' + # rp_from_level is NULL + expected_row['rp_from_level'] = None + # rp_to_level is NULL + expected_row['rp_to_level'] = None + obj_id = self.insert_check('vw_qgep_reach', row, expected_row) + # reach_point has on rp_to as Z NaN: SELECT ST_SetSRID( ST_MakePoint(1,2,'NaN'), 2056) + row = self.select('reach_point', 'BBB 1337_0001') + assert row['situation_geometry'] == '01010000A008080000000000000000F03F0000000000000040000000000000F87F' + # reach_point has on rp_from as Z NaN: SELECT ST_SetSRID( ST_MakePoint(7,8,'NaN'), 2056) + row = self.select('reach_point', 'CCC 1337_0001') + assert row['situation_geometry'] == '01010000A0080800000000000000001C400000000000002040000000000000F87F' + + # 2. insert geometry with Z and no rp_from_level and 66 as rp_to_level + # INSERT INTO qgep_od.vw_qgep_reach (obj_id, progression_geometry, rp_to_level, rp_from_obj_id, rp_to_obj_id) VALUES ('AAA 1337_0002', ST_SetSRID(ST_GeomFromText('COMPOUNDCURVE Z ((1 2 3,4 5 6,7 8 9))'), 2056), 66, 'BBB 1337_0002', 'CCC 1337_0002' ); + row = { + 'progression_geometry': '01090000A00808000001000000010200008003000000000000000000F03F000000000000004000000000000008400000000000001040000000000000144000000000000018400000000000001C4000000000000020400000000000002240', + 'rp_to_level': '66', + 'rp_from_obj_id': 'BBB 1337_0002', + 'rp_to_obj_id': 'CCC 1337_0002' + } + expected_row = copy.deepcopy(row) + # vw_qgep_reach has the geometry but NaN as Z on start_point and 66 (rp_to_level) as Z on end_point: SELECT ST_SetSRID( ST_ForceCurve(ST_MakeLine(ARRAY[ST_MakePoint(1,2,'NaN'), ST_MakePoint(4,5,6), ST_MakePoint(7,8,66)])), 2056) + expected_row['progression_geometry'] = '01090000A00808000001000000010200008003000000000000000000F03F0000000000000040000000000000F87F0000000000001040000000000000144000000000000018400000000000001C4000000000000020400000000000805040' + # rp_from_level is NULL + expected_row['rp_from_level'] = None + # rp_to_level is 66.000 + expected_row['rp_to_level'] = '66.000' + obj_id = self.insert_check('vw_qgep_reach', row, expected_row) + # reach_point has on rp_from as Z NaN: SELECT ST_SetSRID( ST_MakePoint(1,2,'NaN'), 2056) + row = self.select('reach_point', 'BBB 1337_0002') + assert row['situation_geometry'] == '01010000A008080000000000000000F03F0000000000000040000000000000F87F' + # reach_point has on rp_to as Z 66.000: SELECT ST_SetSRID( ST_MakePoint(7,8,66.000), 2056) + row = self.select('reach_point', 'CCC 1337_0002') + assert row['situation_geometry'] == '01010000A0080800000000000000001C4000000000000020400000000000805040' + + # 3. insert geometry with Z and 77 as rp_from_level and NULL as rp_to_level + # INSERT INTO qgep_od.vw_qgep_reach (obj_id, progression_geometry, rp_from_level, rp_to_level, rp_from_obj_id, rp_to_obj_id) VALUES ('AAA 1337_0003', ST_SetSRID(ST_GeomFromText('COMPOUNDCURVE Z ((1 2 3,4 5 6,7 8 9))'), 2056), NULL, 77, 'BBB 1337_0003', 'CCC 1337_0003' ); + row = { + 'progression_geometry': '01090000A00808000001000000010200008003000000000000000000F03F000000000000004000000000000008400000000000001040000000000000144000000000000018400000000000001C4000000000000020400000000000002240', + 'rp_from_level': '77.000', + 'rp_to_level': None, + 'rp_from_obj_id': 'BBB 1337_0003', + 'rp_to_obj_id': 'CCC 1337_0003' + } + expected_row = copy.deepcopy(row) + # vw_qgep_reach has the geometry but 77 (rp_from_level) as Z on start_point and NaN as Z on end_point: SELECT ST_SetSRID( ST_ForceCurve(ST_MakeLine(ARRAY[ST_MakePoint(1,2,77), ST_MakePoint(4,5,6), ST_MakePoint(7,8,'NaN')])), 2056) + expected_row['progression_geometry'] = '01090000A00808000001000000010200008003000000000000000000F03F000000000000004000000000004053400000000000001040000000000000144000000000000018400000000000001C400000000000002040000000000000F87F' + # rp_from_level is 77.000 + expected_row['rp_from_level'] = '77.000' + # rp_to_level is NULL + expected_row['rp_to_level'] = None + obj_id = self.insert_check('vw_qgep_reach', row, expected_row) + # reach_point has on rp_from as Z 77.000: SELECT ST_SetSRID( ST_MakePoint(1,2,77.000), 2056) + row = self.select('reach_point', 'BBB 1337_0003') + assert row['situation_geometry'] == '01010000A008080000000000000000F03F00000000000000400000000000405340' + # reach_point has on rp_to as Z 66.000: SELECT ST_SetSRID( ST_MakePoint(7,8,'NaN'), 2056) + row = self.select('reach_point', 'CCC 1337_0003') + assert row['situation_geometry'] == '01010000A0080800000000000000001C400000000000002040000000000000F87F' + + + def test_vw_qgep_reach_geometry_update(self): + # first insert + # no Z and no rp_from_level and no rp_to_level + # INSERT INTO qgep_od.vw_qgep_reach (progression_geometry, rp_from_obj_id, rp_to_obj_id) VALUES (ST_SetSRID( ST_ForceCurve(ST_MakeLine(ARRAY[ST_MakePoint(1,2,'NaN'), ST_MakePoint(4,5,'NaN'), ST_MakePoint(7,8,'NaN')])), 2056), 'BBB 1337_1010', 'CCC 1337_1010' ); + row = { + 'progression_geometry': '01090000A00808000001000000010200008003000000000000000000F03F0000000000000040000000000000F87F00000000000010400000000000001440000000000000F87F0000000000001C400000000000002040000000000000F87F', + 'rp_from_obj_id': 'BBB 1337_1010', + 'rp_to_obj_id': 'CCC 1337_1010' + } + obj_id = self.insert('vw_qgep_reach', row) + + # 1. change geometry including Z with startpoint Z 3 and endpoint Z 9, no change on rp_from_level, no change on rp_to_level + # UPDATE qgep_od.vw_qgep_reach SET progression_geometry=ST_SetSRID(ST_GeomFromText('COMPOUNDCURVE Z ((1 2 3,4 5 6,7 8 9))'), 2056) WHERE obj_id=obj_id' + row = { + 'progression_geometry': '01090000A00808000001000000010200008003000000000000000000F03F000000000000004000000000000008400000000000001040000000000000144000000000000018400000000000001C4000000000000020400000000000002240' + } + self.update('vw_qgep_reach', row, obj_id) + new_row = self.select('vw_qgep_reach', obj_id) + # vw_qgep_reach has the geometry + assert new_row['progression_geometry'] == '01090000A00808000001000000010200008003000000000000000000F03F000000000000004000000000000008400000000000001040000000000000144000000000000018400000000000001C4000000000000020400000000000002240' + # rp_from_level is 3 (startpoint of geometry) + assert new_row['rp_from_level'] == 3 + # rp_to_level is 9 (endpoint of geometry) + assert new_row['rp_to_level'] == 9 + # reach_point has on rp_from as Z 3 + new_row = self.select('reach_point', 'BBB 1337_1010') + assert new_row['level'] == 3 + # reach_point has on rp_to as Z 9 + new_row = self.select('reach_point', 'CCC 1337_1010') + assert new_row['level'] == 9 + + # 2. change geometry including Z with startpoint Z 33 and endpoint Z 99, no change on rp_from_level, but change on rp_to_level to NULL + # UPDATE qgep_od.vw_qgep_reach SET progression_geometry=ST_SetSRID(ST_GeomFromText('COMPOUNDCURVE Z ((1 2 33,4 5 6,7 8 99))'), 2056), rp_to_level=NULL WHERE obj_id=obj_id' + row = { + 'progression_geometry': '01090000A00808000001000000010200008003000000000000000000F03F000000000000004000000000008040400000000000001040000000000000144000000000000018400000000000001C4000000000000020400000000000C05840', + 'rp_to_level': None + } + self.update('vw_qgep_reach', row, obj_id) + new_row = self.select('vw_qgep_reach', obj_id) + # vw_qgep_reach has the geometry but as endpoint Z there is NaN: SELECT ST_SetSRID( ST_ForceCurve(ST_MakeLine(ARRAY[ST_MakePoint(1,2,33), ST_MakePoint(4,5,6), ST_MakePoint(7,8,'NaN')])), 2056) + assert new_row['progression_geometry'] == '01090000A00808000001000000010200008003000000000000000000F03F000000000000004000000000008040400000000000001040000000000000144000000000000018400000000000001C400000000000002040000000000000F87F' + # rp_from_level is 33 (startpoint of geometry) + assert new_row['rp_from_level'] == 33 + # rp_to_level is None (endpoint of geometry) and rp_to_level + assert new_row['rp_to_level'] == None + # reach_point has on rp_from as Z 3 + new_row = self.select('reach_point', 'BBB 1337_1010') + assert new_row['level'] == 33 + # reach_point has on rp_to as Z None + new_row = self.select('reach_point', 'CCC 1337_1010') + assert new_row['level'] == None + + # 3. change geometry including Z with startpoint Z 300 and endpoint Z 900, but change on rp_from_level to 333, and change on rp_to_level to 999 + # UPDATE qgep_od.vw_qgep_reach SET progression_geometry=ST_SetSRID(ST_GeomFromText('COMPOUNDCURVE Z ((1 2 300,4 5 6,7 8 900))'), 2056), rp_to_level=NULL WHERE obj_id=obj_id' + row = { + 'progression_geometry': '01090000A00808000001000000010200008003000000000000000000F03F00000000000000400000000000C072400000000000001040000000000000144000000000000018400000000000001C4000000000000020400000000000208C40', + 'rp_from_level': '333.000', + 'rp_to_level': '999.000' + } + self.update('vw_qgep_reach', row, obj_id) + new_row = self.select('vw_qgep_reach', obj_id) + # vw_qgep_reach has the geometry but as startpoint Z is 333 and on endpoint Z is 999: SELECT ST_SetSRID( ST_ForceCurve(ST_MakeLine(ARRAY[ST_MakePoint(1,2,333), ST_MakePoint(4,5,6), ST_MakePoint(7,8,'999)])), 2056) + assert new_row['progression_geometry'] == '01090000A00808000001000000010200008003000000000000000000F03F00000000000000400000000000D074400000000000001040000000000000144000000000000018400000000000001C4000000000000020400000000000388F40' + # rp_from_level is 333 (startpoint of geometry) and rp_from_level + assert new_row['rp_from_level'] == 333 + # rp_to_level is 999 (endpoint of geometry) and rp_to_level + assert new_row['rp_to_level'] == 999 + # reach_point has on rp_from as Z 333 + new_row = self.select('reach_point', 'BBB 1337_1010') + assert new_row['level'] == 333 + # reach_point has on rp_to as Z 999 + new_row = self.select('reach_point', 'CCC 1337_1010') + assert new_row['level'] == 999 + + # 4. change geometry including Z with startpoint Z NaN and endpoint Z NaN, no change on rp_from_level, no change on rp_to_level + # UPDATE qgep_od.vw_qgep_reach SET progression_geometry=ST_SetSRID( ST_ForceCurve(ST_MakeLine(ARRAY[ST_MakePoint(1,2,'NaN'), ST_MakePoint(4,5,6), ST_MakePoint(7,8,'NaN')])), 2056) WHERE obj_id=obj_id' + row = { + 'progression_geometry': '01090000A00808000001000000010200008003000000000000000000F03F0000000000000040000000000000F87F0000000000001040000000000000144000000000000018400000000000001C400000000000002040000000000000F87F' + } + self.update('vw_qgep_reach', row, obj_id) + new_row = self.select('vw_qgep_reach', obj_id) + # vw_qgep_reach has the geometry + assert new_row['progression_geometry'] == '01090000A00808000001000000010200008003000000000000000000F03F0000000000000040000000000000F87F0000000000001040000000000000144000000000000018400000000000001C400000000000002040000000000000F87F' + # rp_from_level is NULL (startpoint of geometry) + assert new_row['rp_from_level'] == None + # rp_to_level is NULL (endpoint of geometry) + assert new_row['rp_to_level'] == None + # reach_point has on rp_from as Z NULL + new_row = self.select('reach_point', 'BBB 1337_1010') + assert new_row['level'] == None + # reach_point has on rp_to as Z NULL + new_row = self.select('reach_point', 'CCC 1337_1010') + assert new_row['level'] == None + + + def test_vw_qgep_wastewater_structure_geometry_insert(self): + # 1. insert geometry with Z and no co_level and no wn_bottom_level + # INSERT INTO qgep_od.vw_qgep_wastewater_structure (situation_geometry, wn_obj_id, co_obj_id) VALUES (ST_SetSRID(ST_Collect(ST_MakePoint(2600000, 1200000, 15000)), 2056), '1337_1001', '1337_1001'); + row = { + 'situation_geometry': '01040000A0080800000100000001010000800000000020D6434100000000804F324100000000004CCD40', + 'wn_obj_id': '1337_1001', + 'co_obj_id': '1337_1001' + } + expected_row = copy.deepcopy(row) + # ws_qgep_wastewaterstructure has the geometry but NaN as Z because of no co_level (geometry of cover): ST_SetSRID(ST_Collect(ST_MakePoint(2600000, 1200000, 'NaN')), 2056) + expected_row['situation_geometry'] = '01040000A0080800000100000001010000800000000020D6434100000000804F3241000000000000F87F' + # co_level is NULL + expected_row['co_level'] = None + # wn_bottom_level NULL + expected_row['wn_bottom_level'] = None + obj_id = self.insert_check('vw_qgep_wastewater_structure', row, expected_row) + # cover geometry has the geometry but NaN as Z: ST_GeometryN( ST_SetSRID(ST_Collect(ST_MakePoint(2600000, 1200000, 'NaN')), 2056), 1 ) + row = self.select('cover', '1337_1001') + assert row['situation_geometry'] == '01010000A0080800000000000020D6434100000000804F3241000000000000F87F' + # wastewater_node has the geometry but NaN as Z: ST_GeometryN( ST_SetSRID(ST_Collect(ST_MakePoint(2600000, 1200000, 'NaN')), 2056), 1 ) + row = self.select('wastewater_node', '1337_1001') + assert row['situation_geometry'] == '01010000A0080800000000000020D6434100000000804F3241000000000000F87F' + + # 2. insert geometry with Z and no co_level and WITH wn_bottom_level + # INSERT INTO qgep_od.vw_qgep_wastewater_structure (situation_geometry, wn_obj_id, co_obj_id, wn_bottom_level) VALUES (ST_SetSRID(ST_Collect(ST_MakePoint(2600000, 1200000, 15000)), 2056), '1337_1002', '1337_1002', 200.000); + row = { + 'situation_geometry': '01040000A0080800000100000001010000800000000020D6434100000000804F324100000000004CCD40', + 'wn_obj_id': '1337_1002', + 'co_obj_id': '1337_1002', + 'wn_bottom_level': '200.000' + } + expected_row = copy.deepcopy(row) + # ws_qgep_wastewaterstructure has the geometry but NaN as Z because of no co_level (geometry of cover): ST_SetSRID(ST_Collect(ST_MakePoint(2600000, 1200000, 'NaN')), 2056) + expected_row['situation_geometry'] = '01040000A0080800000100000001010000800000000020D6434100000000804F3241000000000000F87F' + # co_level is NULL + expected_row['co_level'] = None + # wn_bottom_level is new wn_bottom_level + expected_row['wn_bottom_level'] = '200.000' + obj_id = self.insert_check('vw_qgep_wastewater_structure', row, expected_row) + # cover geometry has the geometry but NaN as Z: ST_GeometryN( ST_SetSRID(ST_Collect(ST_MakePoint(2600000, 1200000, 'NaN')), 2056), 1 ) + row = self.select('cover', '1337_1002') + assert row['situation_geometry'] == '01010000A0080800000000000020D6434100000000804F3241000000000000F87F' + # wastewater_node has the geometry and wn_buttom_level as Z: ST_GeometryN( ST_SetSRID(ST_Collect(ST_MakePoint(2600000, 1200000, 200)), 2056), 1 ) + row = self.select('wastewater_node', '1337_1002') + assert row['situation_geometry'] == '01010000A0080800000000000020D6434100000000804F32410000000000006940' + + # 3. insert geometry with Z and WITH co_level and WITH wn_bottom_level + # INSERT INTO qgep_od.vw_qgep_wastewater_structure (situation_geometry, wn_obj_id, co_obj_id, wn_bottom_level, co_level) VALUES (ST_SetSRID(ST_Collect(ST_MakePoint(2600000, 1200000, 15000)), 2056), '1337_1003', '1337_1003', 200.000, 500.000); + row = { + 'situation_geometry': '01040000A0080800000100000001010000800000000020D6434100000000804F324100000000004CCD40', + 'wn_obj_id': '1337_1003', + 'co_obj_id': '1337_1003', + 'wn_bottom_level': '200.000', + 'co_level': '500.000' + } + expected_row = copy.deepcopy(row) + # ws_qgep_wastewaterstructure has the geometry and co_level as Z (geometry of cover): ST_SetSRID(ST_Collect(ST_MakePoint(2600000, 1200000, 500)), 2056) + expected_row['situation_geometry'] = '01040000A0080800000100000001010000800000000020D6434100000000804F32410000000000407F40' + # co_level is new co_level + expected_row['co_level'] = '500.000' + # wn_bottom_level is new wn_bottom_level + expected_row['wn_bottom_level'] = '200.000' + obj_id = self.insert_check('vw_qgep_wastewater_structure', row, expected_row) + # cover geometry has the geometry and co_level as Z: ST_GeometryN( ST_SetSRID(ST_Collect(ST_MakePoint(2600000, 1200000, 500)), 2056), 1 ) + row = self.select('cover', '1337_1003') + assert row['situation_geometry'] == '01010000A0080800000000000020D6434100000000804F32410000000000407F40' + # wastewater_node has the geometry and wn_buttom_level as Z: ST_GeometryN( ST_SetSRID(ST_Collect(ST_MakePoint(2600000, 1200000, 200)), 2056), 1 ) + row = self.select('wastewater_node', '1337_1003') + assert row['situation_geometry'] == '01010000A0080800000000000020D6434100000000804F32410000000000006940' + + + def test_vw_qgep_wastewater_structure_geometry_update(self): + # first insert + # insert geometry with no Z and no co_level and no wn_bottom_level + # INSERT INTO qgep_od.vw_qgep_wastewater_structure (situation_geometry, wn_obj_id, co_obj_id) VALUES (ST_SetSRID(ST_Collect(ST_MakePoint(2600000, 1200000, 'NaN')), 2056), '1337_1010', '1337_1010'); + row = { + 'situation_geometry': '01040000A0080800000100000001010000800000000020D6434100000000804F3241000000000000F87F', + 'ws_type': 'manhole', + 'wn_obj_id': '1337_1010', + 'co_obj_id': '1337_1010' + } + obj_id = self.insert('vw_qgep_wastewater_structure', row) + + # 1. update no change on geometry with Z but WITH wn_bottom_level + # UPDATE qgep_od.vw_wastewater_node SET wn_bottom_level=200.000 WHERE obj_id = obj_id + row = { + 'wn_bottom_level': '200.000' + } + self.update('vw_qgep_wastewater_structure', row, obj_id) + new_row = self.select('vw_qgep_wastewater_structure', obj_id) + # no change on geometry of ws_qgep_wastewaterstructure (because it's geometry of cover that does not change) + assert new_row['situation_geometry'] == '01040000A0080800000100000001010000800000000020D6434100000000804F3241000000000000F87F' + # no change on co_level + assert new_row['co_level'] == None + # wn_bottom_level is new wn_bottom_level + assert new_row['wn_bottom_level'] == 200.000 + # no change on cover geometry: ST_GeometryN( ST_SetSRID(ST_Collect(ST_MakePoint(2600000, 1200000, 'NaN')), 2056), 1 ) + new_row = self.select('cover', '1337_1010') + assert new_row['situation_geometry'] == '01010000A0080800000000000020D6434100000000804F3241000000000000F87F' + # wastewater_node geometry has Z from new wn_bottom_level: ST_GeometryN( ST_SetSRID(ST_Collect(ST_MakePoint(2600000, 1200000, 200)), 2056), 1 ) + new_row = self.select('wastewater_node', '1337_1010') + assert new_row['situation_geometry'] == '01010000A0080800000000000020D6434100000000804F32410000000000006940' + + # 2. update no change on geometry with Z but WITH co_level + # UPDATE qgep_od.vw_wastewater_node SET level=500.000 WHERE obj_id = obj_id + row = { + 'co_level': '500.000' + } + self.update('vw_qgep_wastewater_structure', row, obj_id) + new_row = self.select('vw_qgep_wastewater_structure', obj_id) + # geometry of ws_qgep_wastewaterstructure has co_level as Z (because it's geometry of cover): ST_SetSRID(ST_Collect(ST_MakePoint(2600000, 1200000, 500)), 2056) + assert new_row['situation_geometry'] == '01040000A0080800000100000001010000800000000020D6434100000000804F32410000000000407F40' + # co_level is new co_level + assert new_row['co_level'] == 500.000 + # no change on wn_bottom_level + assert new_row['wn_bottom_level'] == 200.000 + # cover geometry has Z from new co_level: ST_GeometryN( ST_SetSRID(ST_Collect(ST_MakePoint(2600000, 1200000, 500), 2056), 1 ) + new_row = self.select('cover', '1337_1010') + assert new_row['situation_geometry'] == '01010000A0080800000000000020D6434100000000804F32410000000000407F40' + # no change on wastewater_node geometry: ST_GeometryN( ST_SetSRID(ST_Collect(ST_MakePoint(2600000, 1200000, 200)), 2056), 1 ) + new_row = self.select('wastewater_node', '1337_1010') + assert new_row['situation_geometry'] == '01010000A0080800000000000020D6434100000000804F32410000000000006940' + + # 3. update no change on geometry with Z but WITH co_level and WITH wn_bottom_level + # UPDATE qgep_od.vw_wastewater_node SET co_level=600.000, wn_bottom_level=300.000 WHERE obj_id = obj_id + row = { + 'co_level': '600.000', + 'wn_bottom_level': '300.000' + } + self.update('vw_qgep_wastewater_structure', row, obj_id) + new_row = self.select('vw_qgep_wastewater_structure', obj_id) + # geometry of ws_qgep_wastewaterstructure has co_level as Z (because it's geometry of cover): ST_SetSRID(ST_Collect(ST_MakePoint(2600000, 1200000, 600)), 2056) + assert new_row['situation_geometry'] == '01040000A0080800000100000001010000800000000020D6434100000000804F32410000000000C08240' + # co_level is new co_level + assert new_row['co_level'] == 600.000 + # wn_bottom_level is new wn_bottom_level + assert new_row['wn_bottom_level'] == 300.000 + # cover geometry has Z from new co_level: ST_GeometryN( ST_SetSRID(ST_Collect(ST_MakePoint(2600000, 1200000, 600), 2056), 1 ) + new_row = self.select('cover', '1337_1010') + assert new_row['situation_geometry'] == '01010000A0080800000000000020D6434100000000804F32410000000000C08240' + # no change on wastewater_node geometry: ST_GeometryN( ST_SetSRID(ST_Collect(ST_MakePoint(2600000, 1200000, 300)), 2056), 1 ) + new_row = self.select('wastewater_node', '1337_1010') + assert new_row['situation_geometry'] == '01010000A0080800000000000020D6434100000000804F32410000000000C07240' + + # 4. update change geometry with Z but WITH co_level and WITH wn_bottom_level + # UPDATE qgep_od.vw_wastewater_node SET situation_geometry=ST_SetSRID(ST_Collect(ST_MakePoint(400, 800, 1100)), 2056), co_level=20.000, wn_bottom_level=30.000 WHERE obj_id = obj_id + row = { + 'situation_geometry': '01040000A008080000010000000101000080000000000000794000000000000089400000000000309140', + 'co_level': '20.000', + 'wn_bottom_level': '30.000' + } + self.update('vw_qgep_wastewater_structure', row, obj_id) + new_row = self.select('vw_qgep_wastewater_structure', obj_id) + # geometry of ws_qgep_wastewaterstructure has XY from new geometry and has co_level as Z (because it's geometry of cover): ST_SetSRID(ST_Collect(ST_MakePoint(400, 800, 20)), 2056) + assert new_row['situation_geometry'] == '01040000A008080000010000000101000080000000000000794000000000000089400000000000003440' + # co_level is new co_level + assert new_row['co_level'] == 20.000 + # wn_bottom_level is new wn_bottom_level + assert new_row['wn_bottom_level'] == 30.000 + # cover geometry has XY from new geometry and has Z from new co_level: ST_GeometryN( ST_SetSRID(ST_Collect(ST_MakePoint(400, 800, 20)), 2056), 1 ) + new_row = self.select('cover', '1337_1010') + assert new_row['situation_geometry'] == '01010000A008080000000000000000794000000000000089400000000000003440' + # wastewater_node geometry has XY from new geometry and has Z from new wn_bottom_level: ST_GeometryN( ST_SetSRID(ST_Collect(ST_MakePoint(400, 800, 30)), 2056), 1 ) + new_row = self.select('wastewater_node', '1337_1010') + assert new_row['situation_geometry'] == '01010000A008080000000000000000794000000000000089400000000000003E40' + + + # 5. update change geometry with Z and no change on co_level and no change on wn_bottom_level (never happens, but just in case) + # UPDATE qgep_od.vw_wastewater_node SET situation_geometry=ST_SetSRID(ST_Collect(ST_MakePoint(500, 900, 100)), 2056) WHERE obj_id = obj_id + row = { + 'situation_geometry': '01040000A0080800000100000001010000800000000000407F400000000000208C400000000000005940' + } + self.update('vw_qgep_wastewater_structure', row, obj_id) + new_row = self.select('vw_qgep_wastewater_structure', obj_id) + # geometry of ws_qgep_wastewaterstructure has XY from new geometry but old co_level as Z (because it's geometry of cover): ST_SetSRID(ST_Collect(ST_MakePoint(500, 900, 20)), 2056) + assert new_row['situation_geometry'] == '01040000A0080800000100000001010000800000000000407F400000000000208C400000000000003440' + # co_level is not overwritten with Z value + assert new_row['co_level'] == 20.000 + # wn_bottom_level is not overwritten with Z value + assert new_row['wn_bottom_level'] == 30.000 + # cover geometry has XY from new geometry but old co_level as Z : ST_GeometryN( ST_SetSRID(ST_Collect(ST_MakePoint(500, 900, 20)), 2056), 1 ) + new_row = self.select('cover', '1337_1010') + assert new_row['situation_geometry'] == '01010000A0080800000000000000407F400000000000208C400000000000003440' + # wastewater_node geometry has XY from new geometry but old new wn_bottom_level as Z: ST_GeometryN( ST_SetSRID(ST_Collect(ST_MakePoint(500, 900, 30)), 2056), 1 ) + new_row = self.select('wastewater_node', '1337_1010') + assert new_row['situation_geometry'] == '01010000A0080800000000000000407F400000000000208C400000000000003E40' + + + def test_wastewater_node_geometry_sync_on_insert(self): + # 1. bottom level 200 and no Z + # INSERT INTO qgep_od.vw_wastewater_node (bottom_level, situation_geometry) VALUES (200, ST_SetSRID(ST_MakePoint(2600000, 1200000, 'NaN'), 2056) ); + row = { + 'bottom_level': '200.000', + 'situation_geometry': '01010000A0080800000000000020D6434100000000804F3241000000000000F87F', + } + expected_row = copy.deepcopy(row) + # bottom_level 200 overwrites Z (NaN) results in: ST_SetSRID(ST_MakePoint(2600000, 1200000, 200), 2056) + expected_row['bottom_level'] = '200.000' + expected_row['situation_geometry'] = '01010000A0080800000000000020D6434100000000804F32410000000000006940' + obj_id = self.insert_check('vw_wastewater_node', row, expected_row) + + # 2. bottom level 200 and 555 Z + # INSERT INTO qgep_od.vw_wastewater_node (bottom_level, situation_geometry) VALUES (200, ST_SetSRID(ST_MakePoint(2600000, 1200000, 555), 2056) ); + row = { + 'bottom_level': '200.000', + 'situation_geometry': '01010000A0080800000000000020D6434100000000804F32410000000000588140', + } + expected_row = copy.deepcopy(row) + # bottom_level 200 overwrites Z (555) results in: ST_SetSRID(ST_MakePoint(2600000, 1200000, 200), 2056) + expected_row['bottom_level'] = '200.000' + expected_row['situation_geometry'] = '01010000A0080800000000000020D6434100000000804F32410000000000006940' + obj_id = self.insert_check('vw_wastewater_node', row, expected_row) + + # 3. bottom level NULL and 555 Z + # INSERT INTO qgep_od.vw_wastewater_node (bottom_level, situation_geometry) VALUES (NULL, ST_SetSRID(ST_MakePoint(2600000, 1200000, 555), 2056) ); + row = { + 'bottom_level': None, + 'situation_geometry': '01010000A0080800000000000020D6434100000000804F32410000000000588140', + } + expected_row = copy.deepcopy(row) + # bottom_level NULL overwrites Z (555) (to NaN) results in: ST_SetSRID(ST_MakePoint(2600000, 1200000, 'NaN'), 2056) + expected_row['bottom_level'] = None + expected_row['situation_geometry'] = '01010000A0080800000000000020D6434100000000804F3241000000000000F87F' + obj_id = self.insert_check('vw_wastewater_node', row, expected_row) + + # 4. no bottom level and 555 Z + # INSERT INTO qgep_od.vw_wastewater_node (situation_geometry) VALUES (ST_SetSRID(ST_MakePoint(2600000, 1200000, 555), 2056) ); + row = { + 'situation_geometry': '01010000A0080800000000000020D6434100000000804F32410000000000588140', + } + expected_row = copy.deepcopy(row) + # no bottom_level overwrites Z (555) (to NaN) results in: ST_SetSRID(ST_MakePoint(2600000, 1200000, 'NaN'), 2056) + expected_row['bottom_level'] = None + expected_row['situation_geometry'] = '01010000A0080800000000000020D6434100000000804F3241000000000000F87F' + obj_id = self.insert_check('vw_wastewater_node', row, expected_row) + + + def test_wastewater_node_geometry_sync_on_update(self): + # first insert + # no bottom level and no Z + # INSERT INTO qgep_od.vw_wastewater_node (bottom_level, situation_geometry) VALUES (200, ST_SetSRID(ST_MakePoint(2600000, 1200000, 'NaN'), 2056) ); + row = { + 'situation_geometry': '01010000A0080800000000000020D6434100000000804F3241000000000000F87F', + } + obj_id = self.insert('vw_wastewater_node', row) + + # 1. change Z to 555 (don't change bottom_level) + # UPDATE qgep_od.vw_wastewater_node SET situation_geometry=ST_SetSRID(ST_MakePoint(2600000, 1200000, 555), 2056) WHERE obj_id = obj_id; + row = { + 'situation_geometry': '01010000A0080800000000000020D6434100000000804F32410000000000588140', + } + self.update('vw_wastewater_node', row, obj_id) + # Z (555) overwrites bottom_level results in: 555.000 + new_row = self.select('vw_wastewater_node', obj_id) + assert new_row['situation_geometry'] == '01010000A0080800000000000020D6434100000000804F32410000000000588140' + assert new_row['bottom_level'] == 555.000 + + # 2. change bottom_level to 200 (don't change Z) + # UPDATE qgep_od.vw_wastewater_node SET bottom_level=200 WHERE obj_id = obj_id; + row = { + 'bottom_level': '200.000' + } + self.update('vw_wastewater_node', row, obj_id) + # bottom_level 200 overwrites Z results in: ST_SetSRID(ST_MakePoint(2600000, 1200000, 200), 2056) + new_row = self.select('vw_wastewater_node', obj_id) + assert new_row['situation_geometry'] == '01010000A0080800000000000020D6434100000000804F32410000000000006940' + assert new_row['bottom_level'] == 200.000 + + # 3. change bottom_level to 555 and Z to 666 + # UPDATE qgep_od.vw_wastewater_node SET bottom_level=200 WHERE obj_id = obj_id; + row = { + 'bottom_level': '555.000', + 'situation_geometry': '01010000A0080800000000000020D6434100000000804F32410000000000D08440', + } + self.update('vw_wastewater_node', row, obj_id) + # bottom_level 555 overwrites Z (666) results in: ST_SetSRID(ST_MakePoint(2600000, 1200000, 555), 2056) + new_row = self.select('vw_wastewater_node', obj_id) + assert new_row['situation_geometry'] == '01010000A0080800000000000020D6434100000000804F32410000000000588140' + assert new_row['bottom_level'] == 555.000 + + # 4. change Z to NaN (don't change bottom_level) + # UPDATE qgep_od.vw_wastewater_node SET situation_geometry=ST_SetSRID(ST_MakePoint(2600000, 1200000, 'NaN'), 2056) WHERE obj_id = obj_id; + row = { + 'situation_geometry': '01010000A0080800000000000020D6434100000000804F3241000000000000F87F', + } + self.update('vw_wastewater_node', row, obj_id) + # Z (NaN) overwrites bottom_level results in: NULL + new_row = self.select('vw_wastewater_node', obj_id) + assert new_row['situation_geometry'] == '01010000A0080800000000000020D6434100000000804F3241000000000000F87F' + assert new_row['bottom_level'] == None + + + def test_cover_geometry_sync_on_insert(self): + # 1. level 200 and no Z + # INSERT INTO qgep_od.vw_cover (level, situation_geometry) VALUES (200, ST_SetSRID(ST_MakePoint(2600000, 1200000, 'NaN'), 2056) ); + row = { + 'level': '200.000', + 'situation_geometry': '01010000A0080800000000000020D6434100000000804F3241000000000000F87F', + } + expected_row = copy.deepcopy(row) + # level 200 overwrites Z (NaN) results in: ST_SetSRID(ST_MakePoint(2600000, 1200000, 200), 2056) + expected_row['level'] = '200.000' + expected_row['situation_geometry'] = '01010000A0080800000000000020D6434100000000804F32410000000000006940' + obj_id = self.insert_check('vw_cover', row, expected_row) + + # 2. level 200 and 555 Z + # INSERT INTO qgep_od.vw_cover (level, situation_geometry) VALUES (200, ST_SetSRID(ST_MakePoint(2600000, 1200000, 555), 2056) ); + row = { + 'level': '200.000', + 'situation_geometry': '01010000A0080800000000000020D6434100000000804F32410000000000588140', + } + expected_row = copy.deepcopy(row) + # level 200 overwrites Z (555) results in: ST_SetSRID(ST_MakePoint(2600000, 1200000, 200), 2056) + expected_row['level'] = '200.000' + expected_row['situation_geometry'] = '01010000A0080800000000000020D6434100000000804F32410000000000006940' + obj_id = self.insert_check('vw_cover', row, expected_row) + + # 3. level NULL and 555 Z + # INSERT INTO qgep_od.vw_cover (level, situation_geometry) VALUES (NULL, ST_SetSRID(ST_MakePoint(2600000, 1200000, 555), 2056) ); + row = { + 'level': None, + 'situation_geometry': '01010000A0080800000000000020D6434100000000804F32410000000000588140', + } + expected_row = copy.deepcopy(row) + # level NULL overwrites Z (555) (to NaN) results in: ST_SetSRID(ST_MakePoint(2600000, 1200000, 'NaN'), 2056) + expected_row['level'] = None + expected_row['situation_geometry'] = '01010000A0080800000000000020D6434100000000804F3241000000000000F87F' + obj_id = self.insert_check('vw_cover', row, expected_row) + + # 4. no level and 555 Z + # INSERT INTO qgep_od.vw_cover (situation_geometry) VALUES (ST_SetSRID(ST_MakePoint(2600000, 1200000, 555), 2056) ); + row = { + 'situation_geometry': '01010000A0080800000000000020D6434100000000804F32410000000000588140', + } + expected_row = copy.deepcopy(row) + # no level overwrites Z (555) (to NaN) results in: ST_SetSRID(ST_MakePoint(2600000, 1200000, 'NaN'), 2056) + expected_row['level'] = None + expected_row['situation_geometry'] = '01010000A0080800000000000020D6434100000000804F3241000000000000F87F' + obj_id = self.insert_check('vw_cover', row, expected_row) + + + def test_cover_geometry_sync_on_update(self): + + # first insert + # no level and no Z + # INSERT INTO qgep_od.vw_cover (level, situation_geometry) VALUES (200, ST_SetSRID(ST_MakePoint(2600000, 1200000, 'NaN'), 2056) ); + row = { + 'situation_geometry': '01010000A0080800000000000020D6434100000000804F3241000000000000F87F', + } + obj_id = self.insert('vw_cover', row) + + # 1. change Z to 555 (don't change level) + # UPDATE qgep_od.vw_cover SET situation_geometry=ST_SetSRID(ST_MakePoint(2600000, 1200000, 555), 2056) WHERE obj_id = obj_id; + row = { + 'situation_geometry': '01010000A0080800000000000020D6434100000000804F32410000000000588140', + } + self.update('vw_cover', row, obj_id) + # Z (555) overwrites level results in: 555.000 + new_row = self.select('vw_cover', obj_id) + assert new_row['situation_geometry'] == '01010000A0080800000000000020D6434100000000804F32410000000000588140' + assert new_row['level'] == 555.000 + + # 2. change level to 200 (don't change Z) + # UPDATE qgep_od.vw_cover SET level=200 WHERE obj_id = obj_id; + row = { + 'level': '200.000' + } + self.update('vw_cover', row, obj_id) + # level 200 overwrites Z results in: ST_SetSRID(ST_MakePoint(2600000, 1200000, 200), 2056) + new_row = self.select('vw_cover', obj_id) + assert new_row['situation_geometry'] == '01010000A0080800000000000020D6434100000000804F32410000000000006940' + assert new_row['level'] == 200.000 + + # 3. change level to 555 and Z to 666 + # UPDATE qgep_od.cover_node SET level=200 WHERE obj_id = obj_id; + row = { + 'level': '555.000', + 'situation_geometry': '01010000A0080800000000000020D6434100000000804F32410000000000D08440', + } + self.update('vw_cover', row, obj_id) + # level 555 overwrites Z (666) results in: ST_SetSRID(ST_MakePoint(2600000, 1200000, 555), 2056) + new_row = self.select('vw_cover', obj_id) + assert new_row['situation_geometry'] == '01010000A0080800000000000020D6434100000000804F32410000000000588140' + assert new_row['level'] == 555.000 + + # 4. change Z to NaN (don't change level) + # UPDATE qgep_od.vw_cover SET situation_geometry=ST_SetSRID(ST_MakePoint(2600000, 1200000, 'NaN'), 2056) WHERE obj_id = obj_id; + row = { + 'situation_geometry': '01010000A0080800000000000020D6434100000000804F3241000000000000F87F', + } + self.update('vw_cover', row, obj_id) + # Z (555) overwrites level results in: 555.000 + new_row = self.select('vw_cover', obj_id) + assert new_row['situation_geometry'] == '01010000A0080800000000000020D6434100000000804F3241000000000000F87F' + assert new_row['level'] == None + + + +if __name__ == '__main__': + unittest.main() + diff --git a/test/test_views.py b/test/test_views.py index 1967921b..d7d9203a 100644 --- a/test/test_views.py +++ b/test/test_views.py @@ -77,14 +77,15 @@ def test_vw_qgep_wastewater_structure(self): row = { 'identifier': '20', 'ws_type': 'manhole', - 'situation_geometry': '0104000020080800000100000001010000000000000020D6434100000000804F3241', # SELECT ST_SetSRID(ST_GeomFromText('MULTIPOINT(2600000 1200000)'), 2056) + 'situation_geometry': '01040000A0080800000100000001010000800000000020D6434100000000804F324100000000004CCD40', # SELECT ST_SetSRID(ST_GeomFromText('MULTIPOINTZ(2600000 1200000 15000)'), 2056) 'co_material': 5355, 'wn_backflow_level': decimal.Decimal('100.000') } expected_row = copy.deepcopy(row) - expected_row['situation_geometry'] = '0104000020080800000100000001010000000000000020D6434100000000804F3241' # SELECT ST_SetSRID(ST_GeomFromText('MULTIPOINT(2600000 1200000)'), 2056) - + # be aware the Z variable is overwritten by NaN because co_level is NULL + expected_row['situation_geometry'] = '01040000A0080800000100000001010000800000000020D6434100000000804F3241000000000000F87F' # SELECT ST_SetSRID(ST_Collect(ST_MakePoint(2600000, 1200000, 'NaN')), 2056) + obj_id = self.insert_check('vw_qgep_wastewater_structure', row, expected_row) row = { diff --git a/view/vw_change_points.sql b/view/vw_change_points.sql index dbd3e58d..070b46d0 100644 --- a/view/vw_change_points.sql +++ b/view/vw_change_points.sql @@ -1,7 +1,7 @@ CREATE VIEW qgep_od.vw_change_points AS SELECT rp_to.obj_id, - rp_to.situation_geometry::geometry(Point, :SRID) AS geom, + rp_to.situation_geometry::geometry(POINTZ, :SRID) AS geom, re.material <> re_next.material AS change_in_material, re.clear_height <> re_next.clear_height AS change_in_clear_height, (rp_from.level - rp_to.level) / re.length_effective - (rp_next_from.level - rp_next_to.level) / re_next.length_effective AS change_in_slope diff --git a/view/vw_qgep_reach.sql b/view/vw_qgep_reach.sql index 2f7fccea..7bbe4dc8 100644 --- a/view/vw_qgep_reach.sql +++ b/view/vw_qgep_reach.sql @@ -3,13 +3,6 @@ DROP VIEW IF EXISTS qgep_od.vw_qgep_reach; CREATE OR REPLACE VIEW qgep_od.vw_qgep_reach AS -/* WITH active_maintenance_event AS ( - SELECT me.obj_id, me.identifier, me.active_zone, mews.fk_wastewater_structure FROM qgep_od.maintenance_event me - LEFT JOIN - qgep_od.re_maintenance_event_wastewater_structure mews ON mews.fk_maintenance_event = me.obj_id - WHERE active_zone IS NOT NULL -) */ - SELECT re.obj_id, re.clear_height AS clear_height, re.material, @@ -86,9 +79,6 @@ SELECT re.obj_id, rp_to.fk_dataowner AS rp_to_fk_dataowner, rp_to.fk_provider AS rp_to_fk_provider, rp_to.fk_wastewater_networkelement AS rp_to_fk_wastewater_networkelement - /* am.obj_id AS me_obj_id, - am.active_zone AS me_active_zone, - am.identifier AS me_identifier */ FROM qgep_od.reach re LEFT JOIN qgep_od.wastewater_networkelement ne ON ne.obj_id = re.obj_id LEFT JOIN qgep_od.reach_point rp_from ON rp_from.obj_id = re.fk_reach_point_from @@ -96,7 +86,6 @@ SELECT re.obj_id, LEFT JOIN qgep_od.wastewater_structure ws ON ne.fk_wastewater_structure = ws.obj_id LEFT JOIN qgep_od.channel ch ON ch.obj_id = ws.obj_id LEFT JOIN qgep_od.pipe_profile pp ON re.fk_pipe_profile = pp.obj_id; - /* LEFT JOIN active_maintenance_event am ON am.fk_wastewater_structure = ch.obj_id; */ -- REACH INSERT -- Function: vw_qgep_reach_insert() @@ -105,6 +94,13 @@ CREATE OR REPLACE FUNCTION qgep_od.vw_qgep_reach_insert() RETURNS trigger AS $BODY$ BEGIN + -- Synchronize geometry with level + NEW.progression_geometry = ST_ForceCurve(ST_SetPoint(ST_CurveToLine(NEW.progression_geometry),0, + ST_MakePoint(ST_X(ST_StartPoint(NEW.progression_geometry)),ST_Y(ST_StartPoint(NEW.progression_geometry)),COALESCE(NEW.rp_from_level,'NaN')))); + + NEW.progression_geometry = ST_ForceCurve(ST_SetPoint(ST_CurveToLine(NEW.progression_geometry),ST_NumPoints(NEW.progression_geometry)-1, + ST_MakePoint(ST_X(ST_EndPoint(NEW.progression_geometry)),ST_Y(ST_EndPoint(NEW.progression_geometry)),COALESCE(NEW.rp_to_level,'NaN')))); + INSERT INTO qgep_od.reach_point( obj_id , elevation_accuracy @@ -127,7 +123,7 @@ BEGIN , NEW.rp_from_outlet_shape -- outlet_shape , NEW.rp_from_position_of_connection -- position_of_connection , NEW.rp_from_remark -- remark - , ST_Force2D(ST_StartPoint(NEW.progression_geometry)) -- situation_geometry + , ST_StartPoint(NEW.progression_geometry) -- situation_geometry , NEW.rp_from_last_modification -- last_modification , NEW.rp_from_fk_dataowner -- fk_dataowner , NEW.rp_from_fk_provider -- fk_provider @@ -158,7 +154,7 @@ BEGIN , NEW.rp_to_outlet_shape -- outlet_shape , NEW.rp_to_position_of_connection -- position_of_connection , NEW.rp_to_remark -- remark - , ST_Force2D(ST_EndPoint(NEW.progression_geometry)) -- situation_geometry + , ST_EndPoint(NEW.progression_geometry) -- situation_geometry , NEW.rp_to_last_modification -- last_modification , NEW.rp_to_fk_dataowner -- fk_dataowner , NEW.rp_to_fk_provider -- fk_provider @@ -170,7 +166,6 @@ BEGIN obj_id , accessibility , contract_section - -- , detail_geometry_geometry , financing , gross_costs , identifier @@ -187,16 +182,12 @@ BEGIN , subsidies , year_of_construction , year_of_replacement - -- , last_modification - -- , fk_dataowner - -- , fk_provider , fk_owner , fk_operator ) VALUES ( COALESCE(NEW.fk_wastewater_structure,qgep_sys.generate_oid('qgep_od','channel')) -- obj_id , NEW.ws_accessibility , NEW.ws_contract_section - -- , NEW.detail_geometry_geometry , NEW.ws_financing , NEW.ws_gross_costs , NEW.ws_identifier @@ -213,9 +204,6 @@ BEGIN , NEW.ws_subsidies , NEW.ws_year_of_construction , NEW.ws_year_of_replacement - -- , NEW.ws_last_modification - -- , NEW.fk_dataowner - -- , NEW.fk_provider , NEW.ws_fk_owner , NEW.ws_fk_operator ) @@ -311,10 +299,35 @@ END; $BODY$ CREATE TRIGGER vw_qgep_reach_on_insert INSTEAD OF INSERT ON qgep_od.vw_qgep_reach FOR EACH ROW EXECUTE PROCEDURE qgep_od.vw_qgep_reach_insert(); + -- REACH UPDATE --- Rule: vw_qgep_reach_on_update() +-- Function: vw_qgep_reach_update() + +CREATE OR REPLACE FUNCTION qgep_od.vw_qgep_reach_on_update() + RETURNS trigger AS +$BODY$ +BEGIN + + -- Synchronize geometry with level + IF NEW.rp_from_level <> OLD.rp_from_level OR (NEW.rp_from_level IS NULL AND OLD.rp_from_level IS NOT NULL) OR (NEW.rp_from_level IS NOT NULL AND OLD.rp_from_level IS NULL) THEN + NEW.progression_geometry = ST_ForceCurve(ST_SetPoint(ST_CurveToLine(NEW.progression_geometry),0, + ST_MakePoint(ST_X(ST_StartPoint(NEW.progression_geometry)),ST_Y(ST_StartPoint(NEW.progression_geometry)),COALESCE(NEW.rp_from_level,'NaN')))); + ELSE + IF ST_Z(ST_StartPoint(NEW.progression_geometry)) <> ST_Z(ST_StartPoint(OLD.progression_geometry)) THEN + NEW.rp_from_level = NULLIF(ST_Z(ST_StartPoint(NEW.progression_geometry)),'NaN'); + END IF; + END IF; + + -- Synchronize geometry with level + IF NEW.rp_to_level <> OLD.rp_to_level OR (NEW.rp_to_level IS NULL AND OLD.rp_to_level IS NOT NULL) OR (NEW.rp_to_level IS NOT NULL AND OLD.rp_to_level IS NULL) THEN + NEW.progression_geometry = ST_ForceCurve(ST_SetPoint(ST_CurveToLine(NEW.progression_geometry),ST_NumPoints(NEW.progression_geometry)-1, + ST_MakePoint(ST_X(ST_EndPoint(NEW.progression_geometry)),ST_Y(ST_EndPoint(NEW.progression_geometry)),COALESCE(NEW.rp_to_level,'NaN')))); + ELSE + IF ST_Z(ST_EndPoint(NEW.progression_geometry)) <> ST_Z(ST_EndPoint(OLD.progression_geometry)) THEN + NEW.rp_to_level = NULLIF(ST_Z(ST_EndPoint(NEW.progression_geometry)),'NaN'); + END IF; + END IF; -CREATE OR REPLACE RULE vw_qgep_reach_on_update AS ON UPDATE TO qgep_od.vw_qgep_reach DO INSTEAD ( UPDATE qgep_od.reach_point SET elevation_accuracy = NEW.rp_from_elevation_accuracy @@ -323,7 +336,7 @@ CREATE OR REPLACE RULE vw_qgep_reach_on_update AS ON UPDATE TO qgep_od.vw_qgep_r , outlet_shape = NEW.rp_from_outlet_shape , position_of_connection = NEW.rp_from_position_of_connection , remark = NEW.rp_from_remark - , situation_geometry = ST_Force2D(ST_StartPoint(NEW.progression_geometry)) + , situation_geometry = ST_StartPoint(NEW.progression_geometry) , last_modification = NEW.rp_from_last_modification , fk_dataowner = NEW.rp_from_fk_dataowner , fk_provider = NEW.rp_from_fk_provider @@ -338,7 +351,7 @@ CREATE OR REPLACE RULE vw_qgep_reach_on_update AS ON UPDATE TO qgep_od.vw_qgep_r , outlet_shape = NEW.rp_to_outlet_shape , position_of_connection = NEW.rp_to_position_of_connection , remark = NEW.rp_to_remark - , situation_geometry = ST_Force2D(ST_EndPoint(NEW.progression_geometry)) + , situation_geometry = ST_EndPoint(NEW.progression_geometry) , last_modification = NEW.rp_to_last_modification , fk_dataowner = NEW.rp_to_fk_dataowner , fk_provider = NEW.rp_to_fk_provider @@ -361,7 +374,6 @@ CREATE OR REPLACE RULE vw_qgep_reach_on_update AS ON UPDATE TO qgep_od.vw_qgep_r SET accessibility = NEW.ws_accessibility , contract_section = NEW.ws_contract_section - -- , detail_geometry_geometry = NEW.detail_geometry_geometry , financing = NEW.ws_financing , gross_costs = NEW.ws_gross_costs , identifier = NEW.ws_identifier @@ -414,7 +426,17 @@ CREATE OR REPLACE RULE vw_qgep_reach_on_update AS ON UPDATE TO qgep_od.vw_qgep_r , wall_roughness = NEW.wall_roughness , fk_pipe_profile = NEW.fk_pipe_profile WHERE obj_id = OLD.obj_id; -); + + RETURN NEW; +END; $BODY$ + LANGUAGE plpgsql VOLATILE; + +CREATE TRIGGER vw_qgep_reach_on_update + INSTEAD OF UPDATE + ON qgep_od.vw_qgep_reach + FOR EACH ROW + EXECUTE PROCEDURE qgep_od.vw_qgep_reach_on_update(); + -- REACH DELETE -- Rule: vw_qgep_reach_on_delete() @@ -423,8 +445,6 @@ CREATE OR REPLACE RULE vw_qgep_reach_on_delete AS ON DELETE TO qgep_od.vw_qgep_r DELETE FROM qgep_od.reach WHERE obj_id = OLD.obj_id; ); ---missing: delete also connected wastewater_structure (and subclass channel or other), structure_parts, re_maintenance_events - ALTER VIEW qgep_od.vw_qgep_reach ALTER obj_id SET DEFAULT qgep_sys.generate_oid('qgep_od','reach'); ALTER VIEW qgep_od.vw_qgep_reach ALTER rp_from_obj_id SET DEFAULT qgep_sys.generate_oid('qgep_od','reach_point'); diff --git a/view/vw_qgep_wastewater_structure.sql b/view/vw_qgep_wastewater_structure.sql index b77bc279..9b3c1069 100644 --- a/view/vw_qgep_wastewater_structure.sql +++ b/view/vw_qgep_wastewater_structure.sql @@ -105,7 +105,7 @@ CREATE OR REPLACE VIEW qgep_od.vw_qgep_wastewater_structure AS FROM ( SELECT ws.obj_id, - ST_Collect(co.situation_geometry)::geometry(MultiPoint, :SRID) AS situation_geometry, + ST_Collect(co.situation_geometry)::geometry(MULTIPOINTZ, :SRID) AS situation_geometry, CASE WHEN COUNT(wn.obj_id) = 1 THEN MIN(wn.obj_id) ELSE NULL END AS wn_obj_id FROM qgep_od.wastewater_structure ws FULL OUTER JOIN qgep_od.structure_part sp ON sp.fk_wastewater_structure = ws.obj_id