From 7e5f1376b0a1aed5e3e7cd476edacc415542da02 Mon Sep 17 00:00:00 2001 From: Ryan Lambert Date: Sat, 13 Dec 2025 10:43:19 -0700 Subject: [PATCH 1/4] Set stage to add docs for pgRouting 4 --- docs/src/SUMMARY.md | 2 + docs/src/routing-3.md | 292 ++++++++++++++++++++++++++++++++++++++++++ docs/src/routing-4.md | 5 + docs/src/routing.md | 290 +++-------------------------------------- 4 files changed, 317 insertions(+), 272 deletions(-) create mode 100644 docs/src/routing-3.md create mode 100644 docs/src/routing-4.md diff --git a/docs/src/SUMMARY.md b/docs/src/SUMMARY.md index 84194d5..8306ab2 100644 --- a/docs/src/SUMMARY.md +++ b/docs/src/SUMMARY.md @@ -16,6 +16,8 @@ - [Data Files](./data-files.md) - [Query examples](./query.md) - [Routing](./routing.md) + - [pgRouting 3](./routing-3.md) + - [pgRouting 4](./routing-4.md) - [Processing Time](./performance.md) # Production usages diff --git a/docs/src/routing-3.md b/docs/src/routing-3.md new file mode 100644 index 0000000..1b2cff9 --- /dev/null +++ b/docs/src/routing-3.md @@ -0,0 +1,292 @@ +# Routing with PgOSM Flex and PgRouting prior to 4.0 + + +> If you are using a pgRouting 4.0 or later see [Routing with pgRouting 4](./routing-4.md). + + +To prepare the OpenStreetMap roads data for routing, run the +pgRouting functions `pgr_nodeNetwork()`, `pgr_createTopology()`, +and `pgr_analyzeGraph()`. + + +```sql +SELECT pgr_nodeNetwork('routing.road_line', 0.1, 'id', 'geom'); +SELECT pgr_createTopology('routing.road_line_noded', 0.1, 'geom'); +SELECT pgr_analyzeGraph('routing.road_line_noded', 0.1, 'geom'); +``` + +> Note: These functions were all removed in pgRouting 4.0. + +Running the functions shown above will create two (2) new tables +usable for routing. + +* `routing.road_line_noded` +* `routing.road_line_noded_vertices_pgr` + + +## Timing note + +The pgRouting functions shown in the preceding section can take a +long time to complete on larger regions. +It is often a good idea to run these from `psql` within a screen +emulator, such as `screen` or `tmux` that allow you to disconnect +from the long-running command without cancelling the query. + + +## Determine Costs + +Routing requires a cost in order to determine the best route to +take. +The following query creates a simple `cost_length` column to +the `routing.road_line_noded` table as a generated column. +This is a simple way to get started with costs for routing. + +```sql +ALTER TABLE routing.road_line_noded + ADD cost_length DOUBLE PRECISION NOT NULL + GENERATED ALWAYS AS (ST_Length(geom)) + STORED; +``` + +> Note: This is for non-directional routing. See the *Routing `oneway`* section below for more on directional routing. + + +# Determine route start and end + +The following query identifies the vertex IDs for a start and end point +to use for later queries. The query uses an input set of points +created from specific longitude/latitude values. +Use the `start_id` and `end_id` values from this query +in subsequent queries through the `:start_id` and `:end_id` variables +via DBeaver. + + +```sql +WITH s_point AS ( +SELECT v.id AS start_id + FROM routing.road_line_noded_vertices_pgr v + INNER JOIN (SELECT + ST_Transform(ST_SetSRID(ST_MakePoint(-77.0211, 38.92255), 4326), 3857) + AS geom + ) p ON v.the_geom <-> geom < 10 + ORDER BY v.the_geom <-> geom + LIMIT 1 +), e_point AS ( +SELECT v.id AS end_id + FROM routing.road_line_noded_vertices_pgr v + INNER JOIN (SELECT + ST_Transform(ST_SetSRID(ST_MakePoint(-77.0183, 38.9227), 4326), 3857) + AS geom + ) p ON v.the_geom <-> geom < 10 + ORDER BY v.the_geom <-> geom + LIMIT 1 +) +SELECT s_point.start_id, e_point.end_id + FROM s_point, e_point +; +``` + +```bash +┌──────────┬────────┐ +│ start_id │ end_id │ +╞══════════╪════════╡ +│ 14630 │ 14686 │ +└──────────┴────────┘ +``` + + +> 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. + + +The vertex IDs returned were `14630` and `14686`. These points +span a particular segment of road (`osm_id = 6062791`) that is tagged +as `highway=residential` and `access=private`. +This segment is used to illustrate how the calculated access +control columns, `route_motor`, `route_cycle` and `route_foot`, +can influence route selection. + + + +```sql +SELECT * + FROM routing.road_line + WHERE osm_id = 6062791 +; +``` + +![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) + +> See `flex-config/helpers.lua` functions (e.g. `routable_motor()`) for logic behind access control columns. + + +# Simple route + +Using `pgr_dijkstra()` and no additional filters will +use all roads from OpenStreetMap without regard to mode of travel +or access rules. +This query picks a route that traverses sidewalks and +a section of road with the +[`access=private` tag from OpenStreetMap](https://wiki.openstreetmap.org/wiki/Tag:access%3Dprivate). +The key details to focus on in the following queries +is the string containing a SQL query passed into the `pgr_dijkstra()` +function. This first example is a simple query from the +`routing.road_line_noded` table. + +> 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!). + + +```sql +SELECT d.*, n.the_geom AS node_geom, e.geom AS edge_geom + FROM pgr_dijkstra( + 'SELECT id, source, target, cost_length AS cost, + geom + FROM routing.road_line_noded + ', + :start_id, :end_id, directed := False + ) d + INNER JOIN routing.road_line_noded_vertices_pgr n ON d.node = n.id + LEFT JOIN routing.road_line_noded e ON d.edge = e.id +; +``` + +![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) + + +# Route motorized + +The following query modifies the query passed in to `pgr_dijkstra()` +to join the `routing.road_line_noded` table to the +`routing.road_line` table. This allows using attributes available +in the upstream table for additional routing logic. +The join clause includes a filter on the `route_motor` column. + +From the comment on the `osm.road_line.route_motor` column: + +> "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!" + +Based on this comment, we can expect that adding `AND r.route_motor` +into the filter will ensure the road type is suitable for motorized +traffic, and it excludes routes marked private. + + +```sql +SELECT d.*, n.the_geom AS node_geom, e.geom AS edge_geom + FROM pgr_dijkstra( + 'SELECT n.id, n.source, n.target, n.cost_length AS cost, + n.geom + FROM routing.road_line_noded n + INNER JOIN routing.road_line r ON n.old_id = r.id + AND r.route_motor + ', + :start_id, :end_id, directed := False + ) d + INNER JOIN routing.road_line_noded_vertices_pgr n ON d.node = n.id + LEFT JOIN routing.road_line_noded e ON d.edge = e.id +; +``` + + +![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) + + + +# Route `oneway` + + +The route shown in the previous example now respects the +access control and limits to routes suitable for motorized traffic. +It, however, **did not** respect the one-way access control. +The very first segment (top-left corner of screenshot) went +the wrong way on a one-way street. +This behavior is a result of the simple length-based cost model. + + +The `oneway` column in the road tables uses +[osm2pgsql's `direction` data type](https://osm2pgsql.org/doc/manual.html#type-conversions) which resolves to `int2` in Postgres. +Valid values are: + +* `0`: Not one way +* `1`: One way, forward travel allowed +* `-1`: One way, reverse travel allowed +* `NULL`: It's complicated. See #172. + + +Assuming a noded roads table routing table, bring over the `oneway` detail + +```sql +ALTER TABLE routing.road_line_noded + ADD oneway INT2 NULL +; + +UPDATE routing.road_line_noded rn + SET oneway = r.oneway + FROM routing.road_line r + WHERE rn.old_id = r.id AND rn.oneway IS NULL +; +``` + +## Forward and reverse costs + +Calculate forward cost. + +```sql +ALTER TABLE routing.road_line_noded + DROP COLUMN IF EXISTS cost_length +; + +-- Cost with oneway considerations +ALTER TABLE routing.road_line_noded + ADD cost_length NUMERIC + GENERATED ALWAYS AS ( + CASE WHEN oneway IN (0, 1) OR oneway IS NULL + THEN ST_Length(geom) + WHEN oneway = -1 + THEN -1 * ST_Length(geom) + END + ) + STORED +; +``` + +Reverse cost. + +```sql +-- Reverse cost with oneway considerations +ALTER TABLE routing.road_line_noded + ADD cost_length_reverse NUMERIC + GENERATED ALWAYS AS ( + CASE WHEN oneway IN (0, -1) OR oneway IS NULL + THEN ST_Length(geom) + WHEN oneway = 1 + THEN -1 * ST_Length(geom) + END + ) + STORED +; +``` + + +This query uses the new reverse cost column, and changes +`directed` from `False` to `True`. + + +```sql +SELECT d.*, n.the_geom AS node_geom, e.geom AS edge_geom + FROM pgr_dijkstra( + 'SELECT n.id, n.source, n.target, n.cost_length AS cost, + n.cost_length_reverse AS reverse_cost, + n.geom + FROM routing.road_line_noded n + INNER JOIN routing.road_line r ON n.old_id = r.id + AND r.route_motor + ', + :start_id, :end_id, directed := True + ) d + INNER JOIN routing.road_line_noded_vertices_pgr n ON d.node = n.id + LEFT JOIN routing.road_line_noded e ON d.edge = e.id +; +``` + +![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) + + diff --git a/docs/src/routing-4.md b/docs/src/routing-4.md new file mode 100644 index 0000000..6e58cfd --- /dev/null +++ b/docs/src/routing-4.md @@ -0,0 +1,5 @@ +# Routing with PgOSM Flex and PgRouting 4.0+ + +Coming soon. + +> If you are using a pgRouting older than 4.0 see [Routing with pgRouting 3](./routing-3.md). diff --git a/docs/src/routing.md b/docs/src/routing.md index 56bce5b..ba46410 100644 --- a/docs/src/routing.md +++ b/docs/src/routing.md @@ -104,289 +104,35 @@ CREATE INDEX ix_routing_road_line_osm_id ; ``` -### Run pgRouting functions +### Prepare data for routing -To prepare the OpenStreetMap roads data for routing, run the -pgRouting functions `pgr_nodeNetwork()`, `pgr_createTopology()`, -and `pgr_analyzeGraph()`. +The [pgRouting 4.0 release](https://github.com/pgRouting/pgrouting/releases/tag/v4.0.0) +removed functions previously used for this step. +The remainder of the instructions are scoped to which version of pgRouting you are +using. +Check via: ```sql -SELECT pgr_nodeNetwork('routing.road_line', 0.1, 'id', 'geom'); -SELECT pgr_createTopology('routing.road_line_noded', 0.1, 'geom'); -SELECT pgr_analyzeGraph('routing.road_line_noded', 0.1, 'geom'); +SELECT * FROM pgr_version(); ``` -Running the functions shown above will create two (2) new tables -usable for routing. +The 4.0 instructions are attempting to improve naming conventions for improved +understanding and usability. +The pre-4.0 version uses different naming conventions mostly conforming +to naming conventions of the legacy functions. -* `routing.road_line_noded` -* `routing.road_line_noded_vertices_pgr` +Follow the instructions for your version of pgRouting. -### Timing note +* [Routing with pgRouting 3](./routing-3.md) +* [Routing with pgRouting 4](./routing-4.md) -The pgRouting functions shown in the preceding section can take a -long time to complete on larger regions. -It is often a good idea to run these from `psql` within a screen -emulator, such as `screen` or `tmux` that allow you to disconnect -from the long-running command without cancelling the query. +> PgOSM Flex 1.1.1 and later packages `pgRouting` 4.0. +> If you are using external Postgres +> as the target for your data, the pgRouting version you have installed is in +> your control. -### Determine Costs - -Routing requires a cost in order to determine the best route to -take. -The following query creates a simple `cost_length` column to -the `routing.road_line_noded` table as a generated column. -This is a simple way to get started with costs for routing. - -```sql -ALTER TABLE routing.road_line_noded - ADD cost_length DOUBLE PRECISION NOT NULL - GENERATED ALWAYS AS (ST_Length(geom)) - STORED; -``` - -> Note: This is for non-directional routing. See the *Routing `oneway`* section below for more on directional routing. - - -## Determine route start and end - -The following query identifies the vertex IDs for a start and end point -to use for later queries. The query uses an input set of points -created from specific longitude/latitude values. -Use the `start_id` and `end_id` values from this query -in subsequent queries through the `:start_id` and `:end_id` variables -via DBeaver. - - -```sql -WITH s_point AS ( -SELECT v.id AS start_id - FROM routing.road_line_noded_vertices_pgr v - INNER JOIN (SELECT - ST_Transform(ST_SetSRID(ST_MakePoint(-77.0211, 38.92255), 4326), 3857) - AS geom - ) p ON v.the_geom <-> geom < 10 - ORDER BY v.the_geom <-> geom - LIMIT 1 -), e_point AS ( -SELECT v.id AS end_id - FROM routing.road_line_noded_vertices_pgr v - INNER JOIN (SELECT - ST_Transform(ST_SetSRID(ST_MakePoint(-77.0183, 38.9227), 4326), 3857) - AS geom - ) p ON v.the_geom <-> geom < 10 - ORDER BY v.the_geom <-> geom - LIMIT 1 -) -SELECT s_point.start_id, e_point.end_id - FROM s_point, e_point -; -``` - -```bash -┌──────────┬────────┐ -│ start_id │ end_id │ -╞══════════╪════════╡ -│ 14630 │ 14686 │ -└──────────┴────────┘ -``` - - -> 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. - - -The vertex IDs returned were `14630` and `14686`. These points -span a particular segment of road (`osm_id = 6062791`) that is tagged -as `highway=residential` and `access=private`. -This segment is used to illustrate how the calculated access -control columns, `route_motor`, `route_cycle` and `route_foot`, -can influence route selection. - - - -```sql -SELECT * - FROM routing.road_line - WHERE osm_id = 6062791 -; -``` - -![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) - -> See `flex-config/helpers.lua` functions (e.g. `routable_motor()`) for logic behind access control columns. - - -## Simple route - -Using `pgr_dijkstra()` and no additional filters will -use all roads from OpenStreetMap without regard to mode of travel -or access rules. -This query picks a route that traverses sidewalks and -a section of road with the -[`access=private` tag from OpenStreetMap](https://wiki.openstreetmap.org/wiki/Tag:access%3Dprivate). -The key details to focus on in the following queries -is the string containing a SQL query passed into the `pgr_dijkstra()` -function. This first example is a simple query from the -`routing.road_line_noded` table. - -> 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!). - - -```sql -SELECT d.*, n.the_geom AS node_geom, e.geom AS edge_geom - FROM pgr_dijkstra( - 'SELECT id, source, target, cost_length AS cost, - geom - FROM routing.road_line_noded - ', - :start_id, :end_id, directed := False - ) d - INNER JOIN routing.road_line_noded_vertices_pgr n ON d.node = n.id - LEFT JOIN routing.road_line_noded e ON d.edge = e.id -; -``` - -![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) - - -## Route motorized - -The following query modifies the query passed in to `pgr_dijkstra()` -to join the `routing.road_line_noded` table to the -`routing.road_line` table. This allows using attributes available -in the upstream table for additional routing logic. -The join clause includes a filter on the `route_motor` column. - -From the comment on the `osm.road_line.route_motor` column: - -> "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!" - -Based on this comment, we can expect that adding `AND r.route_motor` -into the filter will ensure the road type is suitable for motorized -traffic, and it excludes routes marked private. - - -```sql -SELECT d.*, n.the_geom AS node_geom, e.geom AS edge_geom - FROM pgr_dijkstra( - 'SELECT n.id, n.source, n.target, n.cost_length AS cost, - n.geom - FROM routing.road_line_noded n - INNER JOIN routing.road_line r ON n.old_id = r.id - AND r.route_motor - ', - :start_id, :end_id, directed := False - ) d - INNER JOIN routing.road_line_noded_vertices_pgr n ON d.node = n.id - LEFT JOIN routing.road_line_noded e ON d.edge = e.id -; -``` - - -![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) - - - -## Route `oneway` - - -The route shown in the previous example now respects the -access control and limits to routes suitable for motorized traffic. -It, however, **did not** respect the one-way access control. -The very first segment (top-left corner of screenshot) went -the wrong way on a one-way street. -This behavior is a result of the simple length-based cost model. - - -The `oneway` column in the road tables uses -[osm2pgsql's `direction` data type](https://osm2pgsql.org/doc/manual.html#type-conversions) which resolves to `int2` in Postgres. -Valid values are: - -* `0`: Not one way -* `1`: One way, forward travel allowed -* `-1`: One way, reverse travel allowed -* `NULL`: It's complicated. See #172. - - -Assuming a noded roads table routing table, bring over the `oneway` detail - -```sql -ALTER TABLE routing.road_line_noded - ADD oneway INT2 NULL -; - -UPDATE routing.road_line_noded rn - SET oneway = r.oneway - FROM routing.road_line r - WHERE rn.old_id = r.id AND rn.oneway IS NULL -; -``` - -### Forward and reverse costs - -Calculate forward cost. - -```sql -ALTER TABLE routing.road_line_noded - DROP COLUMN IF EXISTS cost_length -; - --- Cost with oneway considerations -ALTER TABLE routing.road_line_noded - ADD cost_length NUMERIC - GENERATED ALWAYS AS ( - CASE WHEN oneway IN (0, 1) OR oneway IS NULL - THEN ST_Length(geom) - WHEN oneway = -1 - THEN -1 * ST_Length(geom) - END - ) - STORED -; -``` - -Reverse cost. - -```sql --- Reverse cost with oneway considerations -ALTER TABLE routing.road_line_noded - ADD cost_length_reverse NUMERIC - GENERATED ALWAYS AS ( - CASE WHEN oneway IN (0, -1) OR oneway IS NULL - THEN ST_Length(geom) - WHEN oneway = 1 - THEN -1 * ST_Length(geom) - END - ) - STORED -; -``` - - -This query uses the new reverse cost colum, and changes -`directed` from `False` to `True`. - - -```sql -SELECT d.*, n.the_geom AS node_geom, e.geom AS edge_geom - FROM pgr_dijkstra( - 'SELECT n.id, n.source, n.target, n.cost_length AS cost, - n.cost_length_reverse AS reverse_cost, - n.geom - FROM routing.road_line_noded n - INNER JOIN routing.road_line r ON n.old_id = r.id - AND r.route_motor - ', - :start_id, :end_id, directed := True - ) d - INNER JOIN routing.road_line_noded_vertices_pgr n ON d.node = n.id - LEFT JOIN routing.road_line_noded e ON d.edge = e.id -; -``` - -![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) From ded86eab4435b85dbafcc56cee33977c7503a09a Mon Sep 17 00:00:00 2001 From: Ryan Lambert Date: Sat, 13 Dec 2025 10:47:37 -0700 Subject: [PATCH 2/4] Add drafted SQL queries with notes to work into docs --- .../pgrouting-4-examples-initial-draft.sql | 244 ++++++++++++++++++ 1 file changed, 244 insertions(+) create mode 100644 docs/src/static/pgrouting-4-examples-initial-draft.sql diff --git a/docs/src/static/pgrouting-4-examples-initial-draft.sql b/docs/src/static/pgrouting-4-examples-initial-draft.sql new file mode 100644 index 0000000..a143ded --- /dev/null +++ b/docs/src/static/pgrouting-4-examples-initial-draft.sql @@ -0,0 +1,244 @@ +SELECT * + FROM osm.pgosm_flex +; + + +CREATE EXTENSION IF NOT EXISTS pgrouting; +CREATE SCHEMA IF NOT EXISTS routing; + + +SELECT postgis_full_version(), pgr_version(); + + + +CREATE TABLE routing.road_line AS +WITH a AS ( +-- Remove as many multi-linestrings as possible with ST_LineMerge() +SELECT osm_id, osm_type, maxspeed, oneway, layer, + route_foot, route_cycle, route_motor, access, + ST_LineMerge(geom) AS geom + FROM osm.road_line +), extra_cleanup AS ( +-- Pull out those that are still multi, use ST_Dump() to pull out parts +SELECT osm_id, osm_type, maxspeed, oneway, layer, + route_foot, route_cycle, route_motor, access, + (ST_Dump(geom)).geom AS geom + FROM a + WHERE ST_GeometryType(geom) = 'ST_MultiLineString' +), combined AS ( +-- Combine two sources +SELECT osm_id, osm_type, maxspeed, oneway, layer, + route_foot, route_cycle, route_motor, access, + geom + FROM a + WHERE ST_GeometryType(geom) != 'ST_MultiLineString' +UNION +SELECT osm_id, osm_type, maxspeed, oneway, layer, + route_foot, route_cycle, route_motor, access, + geom + FROM extra_cleanup + -- Some data may be lost here if multi-linestring somehow + -- persists through the extra_cleanup query + WHERE ST_GeometryType(geom) != 'ST_MultiLineString' +) +-- Calculate a new surrogate ID for key +SELECT ROW_NUMBER() OVER (ORDER BY geom) AS id, * + FROM combined + ORDER BY geom +; + + + +COMMENT ON COLUMN routing.road_line.id IS 'Surrogate ID, cannot rely on osm_id being unique after converting multi-linestrings to linestrings.'; +ALTER TABLE routing.road_line + ADD CONSTRAINT pk_routing_road_line PRIMARY KEY (id) +; +CREATE INDEX ix_routing_road_line_osm_id + ON routing.road_line (osm_id) +; + + +SELECT COUNT(*) FROM routing.road_line WHERE route_motor + + +--SELECT pgr_nodeNetwork('routing.road_line', 0.1, 'id', 'geom'); +/* + * Seperate Crossing splits at intersections with actual crossings where both lines + * extend to the other side. + * It does NOT split long lines at intersections where one section extends past + * another section. AKA - T-Intersections. + * Unless Routing functions have become more flexible, this will NOT work with + * most common traffic routing use cases. + * + * The ID comes through the new table with a new sub_id value. + * Only creates records where splitting was done. + * + * Fort Collins sub-region took ~30 seconds + */ +DROP TABLE IF EXISTS routing.road_separate_crossing; +--started at 8:20:30 +CREATE TABLE routing.road_separate_crossing AS +SELECT * +FROM pgr_separateCrossing('SELECT id, geom FROM routing.road_line WHERE route_motor', dryrun => false) +; + +/* + * Takes much longer than pgr_separateCrossing + * + * Seperate Crossing splits at touch points where two lines intersect + * This DOES split long lines at intersections where one section intersects another + * in the middle, AKA t-intesections + * + * The ID comes through the new table with a new sub_id value. + * Only creates records where splitting was done. Will need to merge with + * unsplit lines from source table. + * + * Fort Collins sub-region took 9 minutes (25k inputs, 21k outputs) + * + * NOTE: Only seq, id, sub_id, and geom columns make it to final table. Does not help + * to pass in SELECT * thinking you'll get all the columns in the final table. + * (I tried to be lazier in later steps) + */ +DROP TABLE IF EXISTS routing.road_separate_touching; +CREATE TABLE routing.road_separate_touching AS +SELECT * +FROM pgr_separateTouching('SELECT id, geom FROM routing.road_line WHERE route_motor', dryrun => false) +; + + + +SELECT * FROM routing.road_line +; +SELECT * FROM routing.road_separate_touching +; + +DROP TABLE IF EXISTS routing.road_motor_edges; +CREATE TABLE routing.road_motor_edges AS +WITH split_lines AS ( +SELECT r.id AS parent_id, spl.sub_id, r.osm_id, r.osm_type, r.maxspeed, r.oneway, r.layer + , r.access, spl.geom + FROM routing.road_line r + INNER JOIN routing.road_separate_touching spl + ON r.id = spl.id + WHERE route_motor +), unsplit_lines AS ( +SELECT r.id AS parent_id, 1::INT AS sub_id, r.osm_id, r.osm_type, r.maxspeed, r.oneway, r.layer + , r.access, r.geom + FROM routing.road_line r + LEFT JOIN routing.road_separate_touching spl + ON r.id = spl.id + WHERE spl.id IS NULL + AND r.route_motor +) +SELECT * + FROM split_lines +UNION +SELECT * + FROM unsplit_lines +; + +COMMENT ON TABLE routing.road_motor_edges IS 'OSM road data setup for edges for routing for motorized travel'; +ALTER TABLE routing.road_motor_edges + ADD edge_id BIGINT NOT NULL GENERATED ALWAYS AS IDENTITY PRIMARY KEY; +ALTER TABLE routing.road_motor_edges + ADD source BIGINT; +ALTER TABLE routing.road_motor_edges + ADD target BIGINT; +; +ALTER TABLE routing.road_motor_edges + ADD CONSTRAINT uq_routing_road_motor_edges_parent_id_sub_id + UNIQUE (parent_id, sub_id) +; + + +----------------------------------------------------------------------- +-- SELECT pgr_createTopology('routing.road_line_noded', 0.1, 'geom'); +----------------------------------------------------------------------- +DROP TABLE IF EXISTS routing.road_motor_vertices; +CREATE TABLE routing.road_motor_vertices AS +SELECT * FROM pgr_extractVertices( + 'SELECT edge_id AS id, geom FROM routing.road_motor_edges') +; + + + + +SELECT * +FROM routing.road_motor_vertices +WHERE in_edges IS NOT NULL + OR out_edges IS NOT NULL +; + + + +------------------------------------------------- +--SELECT pgr_analyzeGraph('routing.road_line_noded', 0.1, 'geom'); + +-- Update source column from out_edges + +WITH outgoing AS ( + SELECT id AS source + , unnest(out_edges) AS edge_id + --, x, y + FROM routing.road_motor_vertices +) +UPDATE routing.road_motor_edges e +SET source = o.source--, x1 = x, y1 = y +FROM outgoing o +WHERE e.edge_id = o.edge_id + AND e.source IS NULL +; + +-- Update target colum from in_edges +WITH incoming AS ( + SELECT id AS target + , unnest(in_edges) AS edge_id + --, x, y + FROM routing.road_motor_vertices +) +UPDATE routing.road_motor_edges e +SET target = i.target--, x1 = x, y1 = y +FROM incoming i +WHERE e.edge_id = i.edge_id + AND e.target IS NULL +; + + +SELECT * + FROM routing.road_motor_edges +; + + + +---------------------- +-- TRYING TO CONTINUE HERE! +ALTER TABLE routing.road_motor_edges + ADD cost_length DOUBLE PRECISION NOT NULL + GENERATED ALWAYS AS (ST_Length(geom)) + STORED; + + +/* + * v_start: 12181 +* v_end: 10402 + */ + + +SELECT * FROM routing.road_motor_edges; +SELECT * FROM routing.road_motor_vertices; + + +SELECT d.*, n.geom AS node_geom, e.geom AS edge_geom + FROM pgr_dijkstra( + 'SELECT edge_id AS id, source, target, cost_length AS cost, + geom + FROM routing.road_motor_edges + ', + :start_id, :end_id, directed := False + ) d + INNER JOIN routing.road_motor_vertices n ON d.node = n.id + LEFT JOIN routing.road_motor_edges e ON d.edge = e.edge_id +; + + + From 7d4267252bf6193c1b2041c7ec7d9ec6807e137f Mon Sep 17 00:00:00 2001 From: Ryan Lambert Date: Sun, 14 Dec 2025 09:30:16 -0700 Subject: [PATCH 3/4] Working through the changes for pgRouting 4.0. New version is functionally equivilent to the legacy version with improved names --- docs/src/routing-3.md | 68 +++++- docs/src/routing-4.md | 469 +++++++++++++++++++++++++++++++++++++++++- docs/src/routing.md | 93 ++------- 3 files changed, 551 insertions(+), 79 deletions(-) diff --git a/docs/src/routing-3.md b/docs/src/routing-3.md index 1b2cff9..fe336f8 100644 --- a/docs/src/routing-3.md +++ b/docs/src/routing-3.md @@ -1,10 +1,72 @@ -# Routing with PgOSM Flex and PgRouting prior to 4.0 - +# Routing with PgRouting 3 > If you are using a pgRouting 4.0 or later see [Routing with pgRouting 4](./routing-4.md). -To prepare the OpenStreetMap roads data for routing, run the +## Clean the data + +The following query does the initial cleanup for preparing OpenStreetMap roads +for routing. The following code is converting multi-linestrings to standard +linestrings for subsequent processing steps. + +```sql +CREATE TABLE routing.road_line AS +WITH a AS ( +-- Remove as many multi-linestrings as possible with ST_LineMerge() +SELECT osm_id, osm_type, maxspeed, oneway, layer, + route_foot, route_cycle, route_motor, access, + ST_LineMerge(geom) AS geom + FROM osm.road_line +), extra_cleanup AS ( +-- Pull out those that are still multi, use ST_Dump() to pull out parts +SELECT osm_id, osm_type, maxspeed, oneway, layer, + route_foot, route_cycle, route_motor, access, + (ST_Dump(geom)).geom AS geom + FROM a + WHERE ST_GeometryType(geom) = 'ST_MultiLineString' +), combined AS ( +-- Combine two sources +SELECT osm_id, osm_type, maxspeed, oneway, layer, + route_foot, route_cycle, route_motor, access, + geom + FROM a + WHERE ST_GeometryType(geom) != 'ST_MultiLineString' +UNION +SELECT osm_id, osm_type, maxspeed, oneway, layer, + route_foot, route_cycle, route_motor, access, + geom + FROM extra_cleanup + -- Some data may be lost here if multi-linestring somehow + -- persists through the extra_cleanup query + WHERE ST_GeometryType(geom) != 'ST_MultiLineString' +) +-- Calculate a new surrogate ID for key +SELECT ROW_NUMBER() OVER (ORDER BY geom) AS id, * + FROM combined + ORDER BY geom +; +``` + +The above query creates the `routing.road_line` table. The next step +adds some database best practices to the table: + +* Explain why a surrogate ID was added +* Primary key on the `id` column +* Index on `osm_id` + + +```sql +COMMENT ON COLUMN routing.road_line.id IS 'Surrogate ID, cannot rely on osm_id being unique after converting multi-linestrings to linestrings.'; +ALTER TABLE routing.road_line + ADD CONSTRAINT pk_routing_road_line PRIMARY KEY (id) +; +CREATE INDEX ix_routing_road_line_osm_id + ON routing.road_line (osm_id) +; +``` + +To prepare the OpenStreetMap roads data for routing with the older pgRouting +installation, run the pgRouting functions `pgr_nodeNetwork()`, `pgr_createTopology()`, and `pgr_analyzeGraph()`. diff --git a/docs/src/routing-4.md b/docs/src/routing-4.md index 6e58cfd..69db4dd 100644 --- a/docs/src/routing-4.md +++ b/docs/src/routing-4.md @@ -1,5 +1,468 @@ -# Routing with PgOSM Flex and PgRouting 4.0+ +# Routing with PgRouting 4 + +> If you are using a pgRouting prior to 4.0 see [Routing with pgRouting 3](./routing-3.md). + +## Pre-process the OpenStreetMap Roads + + +## Clean the data + +The following query converts multi-linestring data to multiple rows of +`LINESTRING` records required by `pgRouting`. + + +```sql +CREATE TABLE routing.osm_road_intermediate AS +WITH a AS ( +-- Remove as many multi-linestrings as possible with ST_LineMerge() +SELECT osm_id, osm_type, maxspeed, oneway, layer, + route_foot, route_cycle, route_motor, access, + ST_LineMerge(geom) AS geom + FROM osm.road_line +), extra_cleanup AS ( +-- Pull out those that are still multi, use ST_Dump() to pull out parts +SELECT osm_id, osm_type, maxspeed, oneway, layer, + route_foot, route_cycle, route_motor, access, + (ST_Dump(geom)).geom AS geom + FROM a + WHERE ST_GeometryType(geom) = 'ST_MultiLineString' +), combined AS ( +-- Combine two sources +SELECT osm_id, osm_type, maxspeed, oneway, layer, + route_foot, route_cycle, route_motor, access, + geom + FROM a + WHERE ST_GeometryType(geom) != 'ST_MultiLineString' +UNION +SELECT osm_id, osm_type, maxspeed, oneway, layer, + route_foot, route_cycle, route_motor, access, + geom + FROM extra_cleanup + -- Some data may be lost here if multi-linestring somehow + -- persists through the extra_cleanup query + WHERE ST_GeometryType(geom) != 'ST_MultiLineString' +) +-- Calculate a new surrogate ID for key +SELECT ROW_NUMBER() OVER (ORDER BY geom) AS id, * + FROM combined + ORDER BY geom +; +``` + +The above query creates the `routing.osm_road_intermediate` table. The next step +adds some database best practices to the table: + +* Explain why a surrogate ID was added +* Primary key on the `id` column +* Index on `osm_id` + + +```sql +COMMENT ON COLUMN routing.osm_road_intermediate.id IS 'Surrogate ID, cannot rely on osm_id being unique after converting multi-linestrings to linestrings.'; +ALTER TABLE routing.osm_road_intermediate + ADD CONSTRAINT pk_routing_road_line PRIMARY KEY (id) +; +CREATE INDEX ix_routing_road_line_osm_id + ON routing.osm_road_intermediate (osm_id) +; +``` + + + +## Split Long Segments + +Use the `pgr_separateTouching()` function to split line segments into smaller +segments and persist into a table. +This is necessary because pgRouting can only route through the ends +of line segments. It cannot switch from Line A to Line B from a point in the middle. + +> FIXME: Make this a temp table instead?? It is not needed post-processing. + +> Warning: This is an expensive query that does not parallelize in Postgres. The +> Washington D.C. example (34k rows) takes roughly an hour (55 minutes) to run. + +```sql +DROP TABLE IF EXISTS routing.road_separate_touching; +CREATE TABLE routing.road_separate_touching AS +SELECT * +FROM pgr_separateTouching('SELECT id, geom FROM routing.osm_road_intermediate') +; +``` + +> The `pgr_separateTouching()` function supports a parameter `dry_run => true` that +> returns the queries it runs instead of running the queries. + + +## Combine Split Lines with Unmodified Lines + +The `routing.road_separate_touching` table created using `pgr_separateTouching()` +has one row for each segment of the lines split by the function. +It does not contain every line from the source table. +The following query combines the two result sets. + +A few column notes: + +* `r.id`, created as surrogate key in `routing.osm_road_intermediate` is now aliased as `parent_id` +* `sub_id` is created by `pgr_separateTouching()` +* A new `edge_id` surrogate ID is created as `PRIMARY KEY` on the table. + + + +```sql +DROP TABLE IF EXISTS routing.osm_road_edge; +CREATE TABLE routing.osm_road_edge AS +WITH split_lines AS ( +SELECT r.id AS parent_id, spl.sub_id, r.osm_id, r.osm_type, r.maxspeed, r.oneway, r.layer + , route_foot, route_cycle, route_motor + , r.access, spl.geom + FROM routing.osm_road_intermediate r + INNER JOIN routing.road_separate_touching spl + ON r.id = spl.id +), unsplit_lines AS ( +SELECT r.id AS parent_id, 1::INT AS sub_id, r.osm_id, r.osm_type, r.maxspeed, r.oneway, r.layer + , route_foot, route_cycle, route_motor + , r.access, r.geom + FROM routing.osm_road_intermediate r +LEFT JOIN routing.road_separate_touching spl + ON r.id = spl.id +WHERE spl.id IS NULL +) +SELECT * + FROM split_lines +UNION +SELECT * + FROM unsplit_lines +; + +COMMENT ON TABLE routing.osm_road_edge IS 'OSM road data setup for edges for routing for motorized travel'; +ALTER TABLE routing.osm_road_edge + ADD edge_id BIGINT NOT NULL GENERATED ALWAYS AS IDENTITY PRIMARY KEY; +ALTER TABLE routing.osm_road_edge + ADD source BIGINT; +ALTER TABLE routing.osm_road_edge + ADD target BIGINT; +; +ALTER TABLE routing.osm_road_edge + ADD CONSTRAINT uq_routing_road_edges_parent_id_sub_id + UNIQUE (parent_id, sub_id) +; +``` + +> At this point, the `routing.osm_road_intermediate` is no longer necessary +> and can be dropped, unless troubleshooting is required within the data pipeline. + + +## Create Vertices + +The `pgr_extractVertices()` function is used to create the vertices from the +`edges`. Each vertex is the start or end point for one or more edges. + + +```sql +DROP TABLE IF EXISTS routing.osm_road_vertex; +CREATE TABLE routing.osm_road_vertex AS +SELECT * FROM pgr_extractVertices( + 'SELECT edge_id AS id, geom FROM routing.osm_road_edge') +; +``` + +Shouldn't be any records with neither in/out edges set. + +```sql +SELECT * +FROM routing.osm_road_vertex +WHERE in_edges IS NULL + AND out_edges IS NULL +; +``` + + +Update the edges table with information about vertices. + +```sql +-- Update source column from out_edges +WITH outgoing AS ( + SELECT id AS source + , unnest(out_edges) AS edge_id + FROM routing.osm_road_vertex +) +UPDATE routing.osm_road_edge e +SET source = o.source +FROM outgoing o +WHERE e.edge_id = o.edge_id + AND e.source IS NULL +; + +-- Update target column from in_edges +WITH incoming AS ( + SELECT id AS target + , unnest(in_edges) AS edge_id + FROM routing.osm_road_vertex +) +UPDATE routing.osm_road_edge e +SET target = i.target +FROM incoming i +WHERE e.edge_id = i.edge_id + AND e.target IS NULL +; +``` + +Should not be any records that are `NULL` in both `source` and `target`. + +```sql +SELECT * + FROM routing.osm_road_edge + WHERE source IS NULL + AND target IS NULL +; +``` + + +## Costs + +The following query establishes a simple length based cost. In the case of defaults +with PgOSM Flex, this results in costs in meters. + +```sql +ALTER TABLE routing.osm_road_edge + ADD cost_length DOUBLE PRECISION NOT NULL + GENERATED ALWAYS AS (ST_Length(geom)) + STORED +; +COMMENT ON COLUMN routing.osm_road_edge.cost_length IS 'Length based cost. Units are determined by SRID of geom data.'; +``` + + +# Determine route start and end + +The following query identifies the vertex IDs for a start and end point +to use for later queries. The query uses an input set of points +created from specific longitude/latitude values. +Use the `start_id` and `end_id` values from this query +in subsequent queries through the `:start_id` and `:end_id` variables +via DBeaver. + + +```sql +WITH s_point AS ( +SELECT v.id AS start_id, v.geom + FROM routing.osm_road_vertex v + INNER JOIN (SELECT + ST_Transform(ST_SetSRID(ST_MakePoint(-77.0211, 38.92255), 4326), 3857) + AS geom + ) p ON v.geom <-> p.geom < 20 + ORDER BY v.geom <-> p.geom + LIMIT 1 +), e_point AS ( +SELECT v.id AS end_id, v.geom + FROM routing.osm_road_vertex v + INNER JOIN (SELECT + ST_Transform(ST_SetSRID(ST_MakePoint(-77.0183, 38.9227), 4326), 3857) + AS geom + ) p ON v.geom <-> p.geom < 20 + ORDER BY v.geom <-> p.geom + LIMIT 1 +) +SELECT s_point.start_id, e_point.end_id + , s_point.geom AS geom_start + , e_point.geom AS geom_end + FROM s_point, e_point +; +``` + +```bash +┌──────────┬────────┐ +│ start_id │ end_id │ +╞══════════╪════════╡ +│ 14630 │ 14686 │ +└──────────┴────────┘ +``` + + +> 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. + + +The vertex IDs returned were `14630` and `14686`. These points +span a particular segment of road (`osm_id = 6062791`) that is tagged +as `highway=residential` and `access=private`. +This segment is used to illustrate how the calculated access +control columns, `route_motor`, `route_cycle` and `route_foot`, +can influence route selection. + + + +```sql +SELECT * + FROM routing.road_line + WHERE osm_id = 6062791 +; +``` + +![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) + +> See `flex-config/helpers.lua` functions (e.g. `routable_motor()`) for logic behind access control columns. + + + +## Route! + + +Using `pgr_dijkstra()` and no additional filters will +use all roads from OpenStreetMap without regard to mode of travel +or access rules. +This query picks a route that traverses sidewalks and +a section of road with the +[`access=private` tag from OpenStreetMap](https://wiki.openstreetmap.org/wiki/Tag:access%3Dprivate). +The key details to focus on in the following queries +is the string containing a SQL query passed into the `pgr_dijkstra()` +function. This first example is a simple query from the +`routing.osm_road_edge` table. + +> 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!). + + +```sql +SELECT d.*, n.geom AS node_geom, e.geom AS edge_geom + FROM pgr_dijkstra( + 'SELECT edge_id AS id, source, target, cost_length AS cost, + geom + FROM routing.osm_road_edge + ', + :start_id, :end_id, directed := False + ) d + INNER JOIN routing.osm_road_vertex n ON d.node = n.id + LEFT JOIN routing.osm_road_edge e ON d.edge = e.edge_id +; +``` + + +![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) + + + + +# Route motorized + +The following query modifies the query passed in to `pgr_dijkstra()` +to join the `routing.osm_road_edge` table to the +`routing.road_line` table. This allows using attributes available +in the upstream table for additional routing logic. +The join clause includes a filter on the `route_motor` column. + +From the comment on the `osm.road_line.route_motor` column: + +> "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!" + +Based on this comment, we can expect that adding `AND r.route_motor` +into the filter will ensure the road type is suitable for motorized +traffic, and it excludes routes marked private. + + +```sql +SELECT d.*, n.geom AS node_geom, e.geom AS edge_geom + FROM pgr_dijkstra( + 'SELECT e.edge_id AS id, e.source, e.target, e.cost_length AS cost, + e.geom + FROM routing.osm_road_edge e + WHERE e.route_motor + ', + :start_id, :end_id, directed := False + ) d + INNER JOIN routing.osm_road_vertex n ON d.node = n.id + LEFT JOIN routing.osm_road_edge e ON d.edge = e.edge_id +; +``` + + +![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) + + + +# Route `oneway` + + +The route shown in the previous example now respects the +access control and limits to routes suitable for motorized traffic. +It, however, **did not** respect the one-way access control. +The very first segment (top-left corner of screenshot) went +the wrong way on a one-way street. +This behavior is a result of the simple length-based cost model. + + +The `oneway` column in the road tables uses +[osm2pgsql's `direction` data type](https://osm2pgsql.org/doc/manual.html#type-conversions) +which resolves to `int2` in Postgres. Valid values are: + +* `0`: Not one way +* `1`: One way, forward travel allowed +* `-1`: One way, reverse travel allowed +* `NULL`: It's complicated. See [#172](https://github.com/rustprooflabs/pgosm-flex/issues/172). + +The `routing.osm_road_edge` table already has the `oneway` column from the +`osm.road_line` table used as the source. + + +## Forward and reverse costs + +Calculate forward and reverse costs using the `oneway` column. This still provides +a length-based cost. The change is to also enforce direction restrictions within +the cost model. + +```sql +ALTER TABLE routing.osm_road_edge + ADD cost_length_forward NUMERIC + GENERATED ALWAYS AS ( + CASE WHEN oneway IN (0, 1) OR oneway IS NULL + THEN ST_Length(geom) + WHEN oneway = -1 + THEN -1 * ST_Length(geom) + END + ) + STORED +; +``` + +Reverse cost. + +```sql +-- Reverse cost with oneway considerations +ALTER TABLE routing.osm_road_edge + ADD cost_length_reverse NUMERIC + GENERATED ALWAYS AS ( + CASE WHEN oneway IN (0, -1) OR oneway IS NULL + THEN ST_Length(geom) + WHEN oneway = 1 + THEN -1 * ST_Length(geom) + END + ) + STORED +; +``` + + +This query uses the new reverse cost column, and changes +`directed` from `False` to `True`. +If you do not see the route shown in the screenshot below, try switching the +`:start_id` and `:end_id` values. + + +```sql +SELECT d.*, n.geom AS node_geom, e.geom AS edge_geom + FROM pgr_dijkstra( + 'SELECT e.edge_id AS id, e.source, e.target + , e.cost_length_forward AS cost + , e.cost_length_reverse AS reverse_cost + , e.geom + FROM routing.osm_road_edge e + WHERE e.route_motor + ', + :start_id, :end_id, directed := True + ) d + INNER JOIN routing.osm_road_vertex n ON d.node = n.id + LEFT JOIN routing.osm_road_edge e ON d.edge = e.edge_id +; +``` + +![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) -Coming soon. -> If you are using a pgRouting older than 4.0 see [Routing with pgRouting 3](./routing-3.md). diff --git a/docs/src/routing.md b/docs/src/routing.md index ba46410..acd0915 100644 --- a/docs/src/routing.md +++ b/docs/src/routing.md @@ -36,91 +36,30 @@ example. ```sql -CREATE EXTENSION IF NOT EXISTS pgrouting; +CREATE EXTENSION IF NOT EXISTS pgrouting SCHEMA public; CREATE SCHEMA IF NOT EXISTS routing; ``` - - -### Clean the data - -Prepare roads for routing using `pgrouting`` functions. The bulk of -the following code is removing multi-linestrings which cause errors -with pgRouting. - -```sql -CREATE TABLE routing.road_line AS -WITH a AS ( --- Remove as many multi-linestrings as possible with ST_LineMerge() -SELECT osm_id, osm_type, maxspeed, oneway, layer, - route_foot, route_cycle, route_motor, access, - ST_LineMerge(geom) AS geom - FROM osm.road_line -), extra_cleanup AS ( --- Pull out those that are still multi, use ST_Dump() to pull out parts -SELECT osm_id, osm_type, maxspeed, oneway, layer, - route_foot, route_cycle, route_motor, access, - (ST_Dump(geom)).geom AS geom - FROM a - WHERE ST_GeometryType(geom) = 'ST_MultiLineString' -), combined AS ( --- Combine two sources -SELECT osm_id, osm_type, maxspeed, oneway, layer, - route_foot, route_cycle, route_motor, access, - geom - FROM a - WHERE ST_GeometryType(geom) != 'ST_MultiLineString' -UNION -SELECT osm_id, osm_type, maxspeed, oneway, layer, - route_foot, route_cycle, route_motor, access, - geom - FROM extra_cleanup - -- Some data may be lost here if multi-linestring somehow - -- persists through the extra_cleanup query - WHERE ST_GeometryType(geom) != 'ST_MultiLineString' -) --- Calculate a new surrogate ID for key -SELECT ROW_NUMBER() OVER (ORDER BY geom) AS id, * - FROM combined - ORDER BY geom -; -``` - -The above query creates the `routing.road_line` table. The next step -adds some database best practices to the table: - -* Explain why a surrogate ID was added -* Primary key on the `id` column -* Index on `osm_id` - - -```sql -COMMENT ON COLUMN routing.road_line.id IS 'Surrogate ID, cannot rely on osm_id being unique after converting multi-linestrings to linestrings.'; -ALTER TABLE routing.road_line - ADD CONSTRAINT pk_routing_road_line PRIMARY KEY (id) -; -CREATE INDEX ix_routing_road_line_osm_id - ON routing.road_line (osm_id) -; -``` +> This command explicitly specifies the `public` schema to enforce the expected default +> and avoid unexpected behavior with custom `search_path` settings. ### Prepare data for routing The [pgRouting 4.0 release](https://github.com/pgRouting/pgrouting/releases/tag/v4.0.0) -removed functions previously used for this step. -The remainder of the instructions are scoped to which version of pgRouting you are -using. +removed functions previously used for data preparation in the original documentation. -Check via: +The routing setup instructions are now scoped to which version of pgRouting you are +using. You can check your version with `pgr_version()`. ```sql SELECT * FROM pgr_version(); ``` -The 4.0 instructions are attempting to improve naming conventions for improved -understanding and usability. -The pre-4.0 version uses different naming conventions mostly conforming -to naming conventions of the legacy functions. +``` +pgr_version| +-----------+ +4.0.0 | +``` Follow the instructions for your version of pgRouting. @@ -128,7 +67,6 @@ Follow the instructions for your version of pgRouting. * [Routing with pgRouting 3](./routing-3.md) * [Routing with pgRouting 4](./routing-4.md) - > PgOSM Flex 1.1.1 and later packages `pgRouting` 4.0. > If you are using external Postgres > as the target for your data, the pgRouting version you have installed is in @@ -136,3 +74,12 @@ Follow the instructions for your version of pgRouting. +The 4.0 instructions have been rewritten to improve naming conventions and reduce +artifacts left behind from the process. The goal with the rewritten docs is improved +understanding and usability. + +The pre-4.0 documentation used naming conventions aimed at conforming +to pgRouting's naming conventions surrounding the legacy functions. + + + From ce6ae453ac91256c175f53974583ce9c36990a07 Mon Sep 17 00:00:00 2001 From: Ryan Lambert Date: Sun, 14 Dec 2025 09:44:33 -0700 Subject: [PATCH 4/4] Add notes about cleaning out middle tables. Remove SQL script, the docs are better than that draft file. --- docs/src/routing-4.md | 27 +- .../pgrouting-4-examples-initial-draft.sql | 244 ------------------ 2 files changed, 18 insertions(+), 253 deletions(-) delete mode 100644 docs/src/static/pgrouting-4-examples-initial-draft.sql diff --git a/docs/src/routing-4.md b/docs/src/routing-4.md index 69db4dd..1809883 100644 --- a/docs/src/routing-4.md +++ b/docs/src/routing-4.md @@ -4,12 +4,8 @@ ## Pre-process the OpenStreetMap Roads - -## Clean the data - -The following query converts multi-linestring data to multiple rows of -`LINESTRING` records required by `pgRouting`. - +The following query converts `ST_MultiLineString` data to individual rows of +`LINESTRING` records. ```sql CREATE TABLE routing.osm_road_intermediate AS @@ -68,7 +64,6 @@ CREATE INDEX ix_routing_road_line_osm_id ``` - ## Split Long Segments Use the `pgr_separateTouching()` function to split line segments into smaller @@ -76,10 +71,10 @@ segments and persist into a table. This is necessary because pgRouting can only route through the ends of line segments. It cannot switch from Line A to Line B from a point in the middle. -> FIXME: Make this a temp table instead?? It is not needed post-processing. > Warning: This is an expensive query that does not parallelize in Postgres. The -> Washington D.C. example (34k rows) takes roughly an hour (55 minutes) to run. +> Washington D.C. example (34k rows) takes roughly an hour (55 minutes) to run +> in Docker on my laptop. ```sql DROP TABLE IF EXISTS routing.road_separate_touching; @@ -242,6 +237,9 @@ Use the `start_id` and `end_id` values from this query in subsequent queries through the `:start_id` and `:end_id` variables via DBeaver. +> This query simulates a GUI allowing user to click on start/end points on a map, +> resulting in longitude and latitude values. + ```sql WITH s_point AS ( @@ -466,3 +464,14 @@ SELECT d.*, n.geom AS node_geom, e.geom AS edge_geom ![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) + +## Cleanup Intermediary tables + +There are 2 tables used to build the routing network that are not needed +after the `routing.osm_road_edge` and `routing.osm_road_vertex` tables are +populated. + +```sql +DROP TABLE IF EXISTS routing.osm_road_intermediate; +DROP TABLE IF EXISTS routing.road_separate_touching; +``` diff --git a/docs/src/static/pgrouting-4-examples-initial-draft.sql b/docs/src/static/pgrouting-4-examples-initial-draft.sql deleted file mode 100644 index a143ded..0000000 --- a/docs/src/static/pgrouting-4-examples-initial-draft.sql +++ /dev/null @@ -1,244 +0,0 @@ -SELECT * - FROM osm.pgosm_flex -; - - -CREATE EXTENSION IF NOT EXISTS pgrouting; -CREATE SCHEMA IF NOT EXISTS routing; - - -SELECT postgis_full_version(), pgr_version(); - - - -CREATE TABLE routing.road_line AS -WITH a AS ( --- Remove as many multi-linestrings as possible with ST_LineMerge() -SELECT osm_id, osm_type, maxspeed, oneway, layer, - route_foot, route_cycle, route_motor, access, - ST_LineMerge(geom) AS geom - FROM osm.road_line -), extra_cleanup AS ( --- Pull out those that are still multi, use ST_Dump() to pull out parts -SELECT osm_id, osm_type, maxspeed, oneway, layer, - route_foot, route_cycle, route_motor, access, - (ST_Dump(geom)).geom AS geom - FROM a - WHERE ST_GeometryType(geom) = 'ST_MultiLineString' -), combined AS ( --- Combine two sources -SELECT osm_id, osm_type, maxspeed, oneway, layer, - route_foot, route_cycle, route_motor, access, - geom - FROM a - WHERE ST_GeometryType(geom) != 'ST_MultiLineString' -UNION -SELECT osm_id, osm_type, maxspeed, oneway, layer, - route_foot, route_cycle, route_motor, access, - geom - FROM extra_cleanup - -- Some data may be lost here if multi-linestring somehow - -- persists through the extra_cleanup query - WHERE ST_GeometryType(geom) != 'ST_MultiLineString' -) --- Calculate a new surrogate ID for key -SELECT ROW_NUMBER() OVER (ORDER BY geom) AS id, * - FROM combined - ORDER BY geom -; - - - -COMMENT ON COLUMN routing.road_line.id IS 'Surrogate ID, cannot rely on osm_id being unique after converting multi-linestrings to linestrings.'; -ALTER TABLE routing.road_line - ADD CONSTRAINT pk_routing_road_line PRIMARY KEY (id) -; -CREATE INDEX ix_routing_road_line_osm_id - ON routing.road_line (osm_id) -; - - -SELECT COUNT(*) FROM routing.road_line WHERE route_motor - - ---SELECT pgr_nodeNetwork('routing.road_line', 0.1, 'id', 'geom'); -/* - * Seperate Crossing splits at intersections with actual crossings where both lines - * extend to the other side. - * It does NOT split long lines at intersections where one section extends past - * another section. AKA - T-Intersections. - * Unless Routing functions have become more flexible, this will NOT work with - * most common traffic routing use cases. - * - * The ID comes through the new table with a new sub_id value. - * Only creates records where splitting was done. - * - * Fort Collins sub-region took ~30 seconds - */ -DROP TABLE IF EXISTS routing.road_separate_crossing; ---started at 8:20:30 -CREATE TABLE routing.road_separate_crossing AS -SELECT * -FROM pgr_separateCrossing('SELECT id, geom FROM routing.road_line WHERE route_motor', dryrun => false) -; - -/* - * Takes much longer than pgr_separateCrossing - * - * Seperate Crossing splits at touch points where two lines intersect - * This DOES split long lines at intersections where one section intersects another - * in the middle, AKA t-intesections - * - * The ID comes through the new table with a new sub_id value. - * Only creates records where splitting was done. Will need to merge with - * unsplit lines from source table. - * - * Fort Collins sub-region took 9 minutes (25k inputs, 21k outputs) - * - * NOTE: Only seq, id, sub_id, and geom columns make it to final table. Does not help - * to pass in SELECT * thinking you'll get all the columns in the final table. - * (I tried to be lazier in later steps) - */ -DROP TABLE IF EXISTS routing.road_separate_touching; -CREATE TABLE routing.road_separate_touching AS -SELECT * -FROM pgr_separateTouching('SELECT id, geom FROM routing.road_line WHERE route_motor', dryrun => false) -; - - - -SELECT * FROM routing.road_line -; -SELECT * FROM routing.road_separate_touching -; - -DROP TABLE IF EXISTS routing.road_motor_edges; -CREATE TABLE routing.road_motor_edges AS -WITH split_lines AS ( -SELECT r.id AS parent_id, spl.sub_id, r.osm_id, r.osm_type, r.maxspeed, r.oneway, r.layer - , r.access, spl.geom - FROM routing.road_line r - INNER JOIN routing.road_separate_touching spl - ON r.id = spl.id - WHERE route_motor -), unsplit_lines AS ( -SELECT r.id AS parent_id, 1::INT AS sub_id, r.osm_id, r.osm_type, r.maxspeed, r.oneway, r.layer - , r.access, r.geom - FROM routing.road_line r - LEFT JOIN routing.road_separate_touching spl - ON r.id = spl.id - WHERE spl.id IS NULL - AND r.route_motor -) -SELECT * - FROM split_lines -UNION -SELECT * - FROM unsplit_lines -; - -COMMENT ON TABLE routing.road_motor_edges IS 'OSM road data setup for edges for routing for motorized travel'; -ALTER TABLE routing.road_motor_edges - ADD edge_id BIGINT NOT NULL GENERATED ALWAYS AS IDENTITY PRIMARY KEY; -ALTER TABLE routing.road_motor_edges - ADD source BIGINT; -ALTER TABLE routing.road_motor_edges - ADD target BIGINT; -; -ALTER TABLE routing.road_motor_edges - ADD CONSTRAINT uq_routing_road_motor_edges_parent_id_sub_id - UNIQUE (parent_id, sub_id) -; - - ------------------------------------------------------------------------ --- SELECT pgr_createTopology('routing.road_line_noded', 0.1, 'geom'); ------------------------------------------------------------------------ -DROP TABLE IF EXISTS routing.road_motor_vertices; -CREATE TABLE routing.road_motor_vertices AS -SELECT * FROM pgr_extractVertices( - 'SELECT edge_id AS id, geom FROM routing.road_motor_edges') -; - - - - -SELECT * -FROM routing.road_motor_vertices -WHERE in_edges IS NOT NULL - OR out_edges IS NOT NULL -; - - - -------------------------------------------------- ---SELECT pgr_analyzeGraph('routing.road_line_noded', 0.1, 'geom'); - --- Update source column from out_edges - -WITH outgoing AS ( - SELECT id AS source - , unnest(out_edges) AS edge_id - --, x, y - FROM routing.road_motor_vertices -) -UPDATE routing.road_motor_edges e -SET source = o.source--, x1 = x, y1 = y -FROM outgoing o -WHERE e.edge_id = o.edge_id - AND e.source IS NULL -; - --- Update target colum from in_edges -WITH incoming AS ( - SELECT id AS target - , unnest(in_edges) AS edge_id - --, x, y - FROM routing.road_motor_vertices -) -UPDATE routing.road_motor_edges e -SET target = i.target--, x1 = x, y1 = y -FROM incoming i -WHERE e.edge_id = i.edge_id - AND e.target IS NULL -; - - -SELECT * - FROM routing.road_motor_edges -; - - - ----------------------- --- TRYING TO CONTINUE HERE! -ALTER TABLE routing.road_motor_edges - ADD cost_length DOUBLE PRECISION NOT NULL - GENERATED ALWAYS AS (ST_Length(geom)) - STORED; - - -/* - * v_start: 12181 -* v_end: 10402 - */ - - -SELECT * FROM routing.road_motor_edges; -SELECT * FROM routing.road_motor_vertices; - - -SELECT d.*, n.geom AS node_geom, e.geom AS edge_geom - FROM pgr_dijkstra( - 'SELECT edge_id AS id, source, target, cost_length AS cost, - geom - FROM routing.road_motor_edges - ', - :start_id, :end_id, directed := False - ) d - INNER JOIN routing.road_motor_vertices n ON d.node = n.id - LEFT JOIN routing.road_motor_edges e ON d.edge = e.edge_id -; - - -