Skip to content

Commit 7e5f137

Browse files
committed
Set stage to add docs for pgRouting 4
1 parent 7af15f1 commit 7e5f137

File tree

4 files changed

+317
-272
lines changed

4 files changed

+317
-272
lines changed

docs/src/SUMMARY.md

Lines changed: 2 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -16,6 +16,8 @@
1616
- [Data Files](./data-files.md)
1717
- [Query examples](./query.md)
1818
- [Routing](./routing.md)
19+
- [pgRouting 3](./routing-3.md)
20+
- [pgRouting 4](./routing-4.md)
1921
- [Processing Time](./performance.md)
2022

2123
# Production usages

docs/src/routing-3.md

Lines changed: 292 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,292 @@
1+
# Routing with PgOSM Flex and PgRouting prior to 4.0
2+
3+
4+
> If you are using a pgRouting 4.0 or later see [Routing with pgRouting 4](./routing-4.md).
5+
6+
7+
To prepare the OpenStreetMap roads data for routing, run the
8+
pgRouting functions `pgr_nodeNetwork()`, `pgr_createTopology()`,
9+
and `pgr_analyzeGraph()`.
10+
11+
12+
```sql
13+
SELECT pgr_nodeNetwork('routing.road_line', 0.1, 'id', 'geom');
14+
SELECT pgr_createTopology('routing.road_line_noded', 0.1, 'geom');
15+
SELECT pgr_analyzeGraph('routing.road_line_noded', 0.1, 'geom');
16+
```
17+
18+
> Note: These functions were all removed in pgRouting 4.0.
19+
20+
Running the functions shown above will create two (2) new tables
21+
usable for routing.
22+
23+
* `routing.road_line_noded`
24+
* `routing.road_line_noded_vertices_pgr`
25+
26+
27+
## Timing note
28+
29+
The pgRouting functions shown in the preceding section can take a
30+
long time to complete on larger regions.
31+
It is often a good idea to run these from `psql` within a screen
32+
emulator, such as `screen` or `tmux` that allow you to disconnect
33+
from the long-running command without cancelling the query.
34+
35+
36+
## Determine Costs
37+
38+
Routing requires a cost in order to determine the best route to
39+
take.
40+
The following query creates a simple `cost_length` column to
41+
the `routing.road_line_noded` table as a generated column.
42+
This is a simple way to get started with costs for routing.
43+
44+
```sql
45+
ALTER TABLE routing.road_line_noded
46+
ADD cost_length DOUBLE PRECISION NOT NULL
47+
GENERATED ALWAYS AS (ST_Length(geom))
48+
STORED;
49+
```
50+
51+
> Note: This is for non-directional routing. See the *Routing `oneway`* section below for more on directional routing.
52+
53+
54+
# Determine route start and end
55+
56+
The following query identifies the vertex IDs for a start and end point
57+
to use for later queries. The query uses an input set of points
58+
created from specific longitude/latitude values.
59+
Use the `start_id` and `end_id` values from this query
60+
in subsequent queries through the `:start_id` and `:end_id` variables
61+
via DBeaver.
62+
63+
64+
```sql
65+
WITH s_point AS (
66+
SELECT v.id AS start_id
67+
FROM routing.road_line_noded_vertices_pgr v
68+
INNER JOIN (SELECT
69+
ST_Transform(ST_SetSRID(ST_MakePoint(-77.0211, 38.92255), 4326), 3857)
70+
AS geom
71+
) p ON v.the_geom <-> geom < 10
72+
ORDER BY v.the_geom <-> geom
73+
LIMIT 1
74+
), e_point AS (
75+
SELECT v.id AS end_id
76+
FROM routing.road_line_noded_vertices_pgr v
77+
INNER JOIN (SELECT
78+
ST_Transform(ST_SetSRID(ST_MakePoint(-77.0183, 38.9227), 4326), 3857)
79+
AS geom
80+
) p ON v.the_geom <-> geom < 10
81+
ORDER BY v.the_geom <-> geom
82+
LIMIT 1
83+
)
84+
SELECT s_point.start_id, e_point.end_id
85+
FROM s_point, e_point
86+
;
87+
```
88+
89+
```bash
90+
┌──────────┬────────┐
91+
│ start_id │ end_id │
92+
╞══════════╪════════╡
93+
│ 14630 │ 14686 │
94+
└──────────┴────────┘
95+
```
96+
97+
98+
> Warning: The vertex IDs returned by the above query will vary. The pgRouting functions that generate this data do not guarantee data will always be generated in precisely the same order, causing these IDs to be different.
99+
100+
101+
The vertex IDs returned were `14630` and `14686`. These points
102+
span a particular segment of road (`osm_id = 6062791`) that is tagged
103+
as `highway=residential` and `access=private`.
104+
This segment is used to illustrate how the calculated access
105+
control columns, `route_motor`, `route_cycle` and `route_foot`,
106+
can influence route selection.
107+
108+
109+
110+
```sql
111+
SELECT *
112+
FROM routing.road_line
113+
WHERE osm_id = 6062791
114+
;
115+
```
116+
117+
![Screenshot from QGIS showing two labeled points, 14630 and 14686. The road between the two points is shown with a light gray dash indicating the access tag indicates non-public travel.](dc-example-route-start-end-vertices.png)
118+
119+
> See `flex-config/helpers.lua` functions (e.g. `routable_motor()`) for logic behind access control columns.
120+
121+
122+
# Simple route
123+
124+
Using `pgr_dijkstra()` and no additional filters will
125+
use all roads from OpenStreetMap without regard to mode of travel
126+
or access rules.
127+
This query picks a route that traverses sidewalks and
128+
a section of road with the
129+
[`access=private` tag from OpenStreetMap](https://wiki.openstreetmap.org/wiki/Tag:access%3Dprivate).
130+
The key details to focus on in the following queries
131+
is the string containing a SQL query passed into the `pgr_dijkstra()`
132+
function. This first example is a simple query from the
133+
`routing.road_line_noded` table.
134+
135+
> Note: These queries are intended to be ran using DBeaver. The `:start_id` and `:end_id` variables work within DBeaver, but not via `psql` or QGIS. Support in other GUIs is unknown at this time (PRs welcome!).
136+
137+
138+
```sql
139+
SELECT d.*, n.the_geom AS node_geom, e.geom AS edge_geom
140+
FROM pgr_dijkstra(
141+
'SELECT id, source, target, cost_length AS cost,
142+
geom
143+
FROM routing.road_line_noded
144+
',
145+
:start_id, :end_id, directed := False
146+
) d
147+
INNER JOIN routing.road_line_noded_vertices_pgr n ON d.node = n.id
148+
LEFT JOIN routing.road_line_noded e ON d.edge = e.id
149+
;
150+
```
151+
152+
![Screenshot from DBeaver showing the route generated with all roads and no access control. The route is direct, traversing the road marked access=private.](dc-example-route-start-no-access-control.png)
153+
154+
155+
# Route motorized
156+
157+
The following query modifies the query passed in to `pgr_dijkstra()`
158+
to join the `routing.road_line_noded` table to the
159+
`routing.road_line` table. This allows using attributes available
160+
in the upstream table for additional routing logic.
161+
The join clause includes a filter on the `route_motor` column.
162+
163+
From the comment on the `osm.road_line.route_motor` column:
164+
165+
> "Best guess if the segment is route-able for motorized traffic. If access is no or private, set to false. WARNING: This does not indicate that this method of travel is safe OR allowed!"
166+
167+
Based on this comment, we can expect that adding `AND r.route_motor`
168+
into the filter will ensure the road type is suitable for motorized
169+
traffic, and it excludes routes marked private.
170+
171+
172+
```sql
173+
SELECT d.*, n.the_geom AS node_geom, e.geom AS edge_geom
174+
FROM pgr_dijkstra(
175+
'SELECT n.id, n.source, n.target, n.cost_length AS cost,
176+
n.geom
177+
FROM routing.road_line_noded n
178+
INNER JOIN routing.road_line r ON n.old_id = r.id
179+
AND r.route_motor
180+
',
181+
:start_id, :end_id, directed := False
182+
) d
183+
INNER JOIN routing.road_line_noded_vertices_pgr n ON d.node = n.id
184+
LEFT JOIN routing.road_line_noded e ON d.edge = e.id
185+
;
186+
```
187+
188+
189+
![Screenshot from DBeaver showing the route generated with all roads and limiting based on route_motor. The route bypasses the road(s) marked access=no and access=private.](dc-example-route-start-motor-access-control.png)
190+
191+
192+
193+
# Route `oneway`
194+
195+
196+
The route shown in the previous example now respects the
197+
access control and limits to routes suitable for motorized traffic.
198+
It, however, **did not** respect the one-way access control.
199+
The very first segment (top-left corner of screenshot) went
200+
the wrong way on a one-way street.
201+
This behavior is a result of the simple length-based cost model.
202+
203+
204+
The `oneway` column in the road tables uses
205+
[osm2pgsql's `direction` data type](https://osm2pgsql.org/doc/manual.html#type-conversions) which resolves to `int2` in Postgres.
206+
Valid values are:
207+
208+
* `0`: Not one way
209+
* `1`: One way, forward travel allowed
210+
* `-1`: One way, reverse travel allowed
211+
* `NULL`: It's complicated. See #172.
212+
213+
214+
Assuming a noded roads table routing table, bring over the `oneway` detail
215+
216+
```sql
217+
ALTER TABLE routing.road_line_noded
218+
ADD oneway INT2 NULL
219+
;
220+
221+
UPDATE routing.road_line_noded rn
222+
SET oneway = r.oneway
223+
FROM routing.road_line r
224+
WHERE rn.old_id = r.id AND rn.oneway IS NULL
225+
;
226+
```
227+
228+
## Forward and reverse costs
229+
230+
Calculate forward cost.
231+
232+
```sql
233+
ALTER TABLE routing.road_line_noded
234+
DROP COLUMN IF EXISTS cost_length
235+
;
236+
237+
-- Cost with oneway considerations
238+
ALTER TABLE routing.road_line_noded
239+
ADD cost_length NUMERIC
240+
GENERATED ALWAYS AS (
241+
CASE WHEN oneway IN (0, 1) OR oneway IS NULL
242+
THEN ST_Length(geom)
243+
WHEN oneway = -1
244+
THEN -1 * ST_Length(geom)
245+
END
246+
)
247+
STORED
248+
;
249+
```
250+
251+
Reverse cost.
252+
253+
```sql
254+
-- Reverse cost with oneway considerations
255+
ALTER TABLE routing.road_line_noded
256+
ADD cost_length_reverse NUMERIC
257+
GENERATED ALWAYS AS (
258+
CASE WHEN oneway IN (0, -1) OR oneway IS NULL
259+
THEN ST_Length(geom)
260+
WHEN oneway = 1
261+
THEN -1 * ST_Length(geom)
262+
END
263+
)
264+
STORED
265+
;
266+
```
267+
268+
269+
This query uses the new reverse cost column, and changes
270+
`directed` from `False` to `True`.
271+
272+
273+
```sql
274+
SELECT d.*, n.the_geom AS node_geom, e.geom AS edge_geom
275+
FROM pgr_dijkstra(
276+
'SELECT n.id, n.source, n.target, n.cost_length AS cost,
277+
n.cost_length_reverse AS reverse_cost,
278+
n.geom
279+
FROM routing.road_line_noded n
280+
INNER JOIN routing.road_line r ON n.old_id = r.id
281+
AND r.route_motor
282+
',
283+
:start_id, :end_id, directed := True
284+
) d
285+
INNER JOIN routing.road_line_noded_vertices_pgr n ON d.node = n.id
286+
LEFT JOIN routing.road_line_noded e ON d.edge = e.id
287+
;
288+
```
289+
290+
![Screenshot from DBeaver showing the route generated with all roads and limiting based on route_motor and using the improved cost model including forward and reverse costs. The route bypasses the road(s) marked access=no and access=private, as well as respects the one-way access controls.](dc-example-route-start-motor-access-control-oneway.png)
291+
292+

docs/src/routing-4.md

Lines changed: 5 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,5 @@
1+
# Routing with PgOSM Flex and PgRouting 4.0+
2+
3+
Coming soon.
4+
5+
> If you are using a pgRouting older than 4.0 see [Routing with pgRouting 3](./routing-3.md).

0 commit comments

Comments
 (0)