Skip to content

Commit

Permalink
Merge pull request #140 from m-kuhn/remove_legacy_functions
Browse files Browse the repository at this point in the history
Use ST_LineSubstring instead of legacy ST_Line_Substring
  • Loading branch information
m-kuhn authored Jun 23, 2020
2 parents 9a8df7e + 0ca0161 commit fb6e5b8
Show file tree
Hide file tree
Showing 3 changed files with 116 additions and 2 deletions.
2 changes: 1 addition & 1 deletion .github/workflows/docker-test-and-push.yaml
Original file line number Diff line number Diff line change
Expand Up @@ -18,7 +18,7 @@ jobs:
strategy:
matrix:
# postgres-postgis version, see available tags https://hub.docker.com/r/postgis/postgis/tags
pgis: ["9.6-2.5", "10-2.5", "11-2.5", "12-2.5"]
pgis: ["9.6-2.5", "10-2.5", "11-2.5", "12-2.5", "9.6-3.0", "10-3.0", "11-3.0", "12-3.0"]
fail-fast: false

env:
Expand Down
2 changes: 1 addition & 1 deletion 07_views_for_network_tracking.sql
Original file line number Diff line number Diff line change
Expand Up @@ -62,7 +62,7 @@ BEGIN
sub2.node_id_1,
sub2.node_id_2,
obj_id,
ST_Line_Substring(
ST_LineSubstring(
ST_CurveToLine(ST_Force2D(progression_geometry)), ratio_1, ratio_2
)
FROM (
Expand Down
114 changes: 114 additions & 0 deletions delta/delta_1.5.1_fix_network_tracking_views.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,114 @@
-- Upgrade topology functions for postgis 3 compatibility (replace legacy ST_Line_Substring with ST_LineSubstring)

CREATE OR REPLACE FUNCTION qgep_network.refresh_network_simple() RETURNS void AS $body$
BEGIN

TRUNCATE qgep_network.segment CASCADE;
TRUNCATE qgep_network.node CASCADE;

-- Insert wastewater nodes
INSERT INTO qgep_network.node(node_type, ne_id, geom)
SELECT
'wastewater_node',
n.obj_id,
ST_Force2D(n.situation_geometry)
FROM qgep_od.wastewater_node n;

-- Insert reachpoints
INSERT INTO qgep_network.node(node_type, ne_id, rp_id, geom)
SELECT
'reach_point',
r.obj_id, -- the reachpoint also keeps a reference to it's reach, as it can be used by blind connections that happen exactly on start/end points
rp.obj_id,
ST_Force2D(rp.situation_geometry)
FROM qgep_od.reach_point rp
JOIN qgep_od.reach r ON rp.obj_id = r.fk_reach_point_from OR rp.obj_id = r.fk_reach_point_to;

-- Insert virtual nodes for blind connections
INSERT INTO qgep_network.node(node_type, ne_id, geom)
SELECT DISTINCT
'blind_connection',
r.obj_id,
ST_ClosestPoint(r.progression_geometry, rp.situation_geometry)
FROM qgep_od.reach r
INNER JOIN qgep_od.reach_point rp ON rp.fk_wastewater_networkelement = r.obj_id
WHERE ST_LineLocatePoint(ST_CurveToLine(r.progression_geometry), rp.situation_geometry) NOT IN (0.0, 1.0); -- if exactly at start or at end, we don't need a virtualnode as we have the reachpoint

-- Insert reaches, subdivided according to blind reaches
INSERT INTO qgep_network.segment (segment_type, from_node, to_node, ne_id, geom)
SELECT 'reach',
sub2.node_id_1,
sub2.node_id_2,
obj_id,
ST_LineSubstring(
ST_CurveToLine(ST_Force2D(progression_geometry)), ratio_1, ratio_2
)
FROM (
-- This subquery uses LAG to combine a node with the next on a reach.
SELECT LAG(sub1.node_id) OVER (PARTITION BY sub1.obj_id ORDER BY sub1.ratio) as node_id_1,
sub1.node_id as node_id_2,
sub1.progression_geometry,
LAG(sub1.ratio) OVER (PARTITION BY sub1.obj_id ORDER BY sub1.ratio) as ratio_1,
sub1.ratio as ratio_2,
obj_id
FROM (
-- This subquery joins blind node to reach, with "ratio" being the position of the node along the reach
SELECT r.obj_id,
r.progression_geometry,
n.id as node_id,
ST_LineLocatePoint(ST_CurveToLine(r.progression_geometry), n.geom) AS ratio
FROM qgep_od.reach r
JOIN qgep_network.node n ON n.ne_id = r.obj_id
) AS sub1
) AS sub2
WHERE ratio_1 IS NOT NULL AND ratio_1 <> ratio_2;

-- Insert edge between reachpoint (from) to the closest node belonging to the wasterwater network element
INSERT INTO qgep_network.segment (segment_type, from_node, to_node, geom)
SELECT DISTINCT ON(n1.id)
'special_structure',
n2.id,
n1.id,
ST_MakeLine(n2.geom, n1.geom)
FROM (

SELECT
rp.obj_id as rp_obj_id,
rp.fk_wastewater_networkelement as wwne_id
FROM qgep_od.reach_point rp
JOIN qgep_od.reach r ON rp.obj_id = r.fk_reach_point_from
WHERE rp.fk_wastewater_networkelement IS NOT NULL

) AS sub1
JOIN qgep_network.node as n1 ON n1.rp_id = rp_obj_id
JOIN qgep_network.node as n2 ON n2.ne_id = wwne_id
ORDER BY n1.id, ST_Distance(n1.geom, n2.geom);

-- Insert edge between reachpoint (to) to the closest node belonging to the wasterwater network element
INSERT INTO qgep_network.segment (segment_type, from_node, to_node, geom)
SELECT DISTINCT ON(n1.id)
'special_structure',
n1.id,
n2.id,
ST_MakeLine(n1.geom, n2.geom)
FROM (

SELECT
rp.obj_id as rp_obj_id,
rp.fk_wastewater_networkelement as wwne_id
FROM qgep_od.reach_point rp
JOIN qgep_od.reach r ON rp.obj_id = r.fk_reach_point_to
WHERE rp.fk_wastewater_networkelement IS NOT NULL

) AS sub1
JOIN qgep_network.node as n1 ON n1.rp_id = rp_obj_id
JOIN qgep_network.node as n2 ON n2.ne_id = wwne_id
ORDER BY n1.id, ST_Distance(n1.geom, n2.geom);

REFRESH MATERIALIZED VIEW qgep_od.vw_network_node;
REFRESH MATERIALIZED VIEW qgep_od.vw_network_segment;

END;
$body$
LANGUAGE plpgsql
SECURITY DEFINER;

0 comments on commit fb6e5b8

Please sign in to comment.