You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
Copy file name to clipboardExpand all lines: db/deploy/routing_functions.sql
+142-2Lines changed: 142 additions & 2 deletions
Original file line number
Diff line number
Diff line change
@@ -317,8 +317,8 @@ BEGIN
317
317
STORED
318
318
;
319
319
320
-
COMMENT ON COLUMN {schema_name}.routing_road_edge.cost_length_forward IS 'Length based cost for forward travel when using directed travel graphs.';
321
-
COMMENT ON COLUMN {schema_name}.routing_road_edge.cost_length_reverse IS 'Length based cost for reverse travel when using directed travel graphs.';
320
+
COMMENT ON COLUMN {schema_name}.routing_road_edge.cost_length_forward IS 'Length based cost for forward travel with directed routing. Based on cost_length value.';
321
+
COMMENT ON COLUMN {schema_name}.routing_road_edge.cost_length_reverse IS 'Length based cost for reverse travel with directed routing. Based on cost_length value.';
322
322
323
323
324
324
DROPTABLE IF EXISTS {schema_name}.routing_road_vertex;
@@ -369,3 +369,143 @@ END $$;
369
369
370
370
371
371
COMMENT ON PROCEDURE {schema_name}.routing_prepare_roads IS 'Creates the {schema_name}.routing_road_edge and {schema_name}.routing_road_vertex from the {schema_name}.road_line input data';
COMMENT ON COLUMN {schema_name}.routing_water_edge.cost_length_forward IS 'Length based cost for forward travel with directed routing. Based on cost_length value.';
460
+
COMMENT ON COLUMN {schema_name}.routing_water_edge.cost_length_reverse IS 'Length based cost for reverse travel with directed routing. Based on cost_length value.';
461
+
462
+
463
+
DROPTABLE IF EXISTS {schema_name}.routing_water_vertex;
464
+
CREATE TABLE {schema_name}.routing_water_vertex AS
465
+
SELECT*FROM pgr_extractVertices(
466
+
'SELECT edge_id AS id, geom FROM {schema_name}.routing_water_edge')
467
+
;
468
+
RAISE NOTICE 'Created table {schema_name}.routing_water_vertex from edges.';
469
+
470
+
CREATEINDEXgix_{schema_name}_routing_water_vertex
471
+
ON {schema_name}.routing_water_vertex
472
+
USING GIST (geom)
473
+
;
474
+
475
+
-- Update source column from out_edges
476
+
WITH outgoing AS (
477
+
SELECT id AS vertex_id_source
478
+
, unnest(out_edges) AS edge_id
479
+
FROM {schema_name}.routing_water_vertex
480
+
)
481
+
UPDATE {schema_name}.routing_water_edge e
482
+
SET vertex_id_source =o.vertex_id_source
483
+
FROM outgoing o
484
+
WHEREe.edge_id=o.edge_id
485
+
ANDe.vertex_id_source IS NULL
486
+
;
487
+
488
+
-- Update target column from in_edges
489
+
WITH incoming AS (
490
+
SELECT id AS vertex_id_target
491
+
, unnest(in_edges) AS edge_id
492
+
FROM {schema_name}.routing_water_vertex
493
+
)
494
+
UPDATE {schema_name}.routing_water_edge e
495
+
SET vertex_id_target =i.vertex_id_target
496
+
FROM incoming i
497
+
WHEREe.edge_id=i.edge_id
498
+
ANDe.vertex_id_target IS NULL
499
+
;
500
+
501
+
502
+
ANALYZE {schema_name}.routing_water_edge;
503
+
ANALYZE {schema_name}.routing_water_vertex;
504
+
505
+
COMMENT ON TABLE {schema_name}.routing_water_vertex IS 'Routing vertex data. These points can be used as the start/end points for routing the edge network in {schema_name}.routing_water_edge..';
506
+
507
+
508
+
END $$;
509
+
510
+
511
+
COMMENT ON PROCEDURE {schema_name}.routing_prepare_water IS 'Creates the {schema_name}.routing_water_edge and {schema_name}.routing_water_vertex from the {schema_name}.water_line input data';
Copy file name to clipboardExpand all lines: docs/src/routing-4.md
+84-12Lines changed: 84 additions & 12 deletions
Display the source diff
Display the rich diff
Original file line number
Diff line number
Diff line change
@@ -87,17 +87,8 @@ This direction data type resolves to `int2` in Postgres. Valid values are:
87
87
*`-1`: One way, reverse travel allowed
88
88
*`NULL`: It's complicated. See [#172](https://github.com/rustprooflabs/pgosm-flex/issues/172).
89
89
90
-
The `osm.routing_road_edge` table has the `oneway` column from the
91
-
`osm.road_line` table used as the source.
92
-
93
-
94
-
Forward and reverse cost columns are calculated within the
95
-
`osm.routing_prepare_roads()` procedure.
96
-
97
-
98
-
Calculate forward and reverse costs using the `oneway` column. This still provides
99
-
a length-based cost. The change is to also enforce direction restrictions within
100
-
the cost model.
90
+
> Forward and reverse cost columns are calculated in the `cost_length_forward`
91
+
> and `cost_length_reverse` columns within the `osm.routing_prepare_roads()` procedure.
101
92
102
93
103
94
## Travel Time Costs
@@ -262,7 +253,7 @@ SELECT d.*, n.geom AS node_geom, e.geom AS edge_geom
262
253
263
254

264
255
265
-
# Oneway-aware routing
256
+
# One-way Aware Routing
266
257
267
258
The route shown in the previous example now respects the
268
259
access control and limits to routes suitable for motorized traffic.
@@ -299,3 +290,84 @@ SELECT d.*, n.geom AS node_geom, e.geom AS edge_geom
299
290
300
291

301
292
293
+
294
+
# Routing with Water
295
+
296
+
PgOSM Flex also includes a procedure to prepare a routing network using
297
+
the `osm.water_line` table.
298
+
299
+
```sql
300
+
CALL osm.routing_prepare_water();
301
+
```
302
+
303
+
Find the `vertex_id` for start and end nodes, similar to approach above
INNER JOINosm.routing_water_vertex n ONd.node=n.id
351
+
LEFT JOINosm.routing_water_edge e ONd.edge=e.edge_id
352
+
;
353
+
```
354
+
355
+

356
+
357
+
## Challenge: Polygons with Water Routing
358
+
359
+
Waterway routing using lines only is often complicated by the nature of waterways
360
+
and the way routes flow through steams and rivers (lines) and also through ponds
361
+
and lakes (polygons). The data prepared by the above procedure only provides
362
+
the line-based functionality.
363
+
364
+
The following image ([source](https://blog.rustprooflabs.com/2022/10/pgrouting-lines-through-polygons))
365
+
visualizes the impact polygons can have on a line-only routing network for water routes.
366
+
367
+

368
+
369
+
370
+
371
+
See the [Routing with Lines through Polygons](https://blog.rustprooflabs.com/2022/10/pgrouting-lines-through-polygons)
372
+
blog post to explore one possible approach to solving this problem.
0 commit comments