|
1 | | -# Routing with PgOSM Flex and PgRouting prior to 4.0 |
2 | | - |
| 1 | +# Routing with PgRouting 3 |
3 | 2 |
|
4 | 3 | > If you are using a pgRouting 4.0 or later see [Routing with pgRouting 4](./routing-4.md). |
5 | 4 |
|
6 | 5 |
|
7 | | -To prepare the OpenStreetMap roads data for routing, run the |
| 6 | +## Clean the data |
| 7 | + |
| 8 | +The following query does the initial cleanup for preparing OpenStreetMap roads |
| 9 | +for routing. The following code is converting multi-linestrings to standard |
| 10 | +linestrings for subsequent processing steps. |
| 11 | + |
| 12 | +```sql |
| 13 | +CREATE TABLE routing.road_line AS |
| 14 | +WITH a AS ( |
| 15 | +-- Remove as many multi-linestrings as possible with ST_LineMerge() |
| 16 | +SELECT osm_id, osm_type, maxspeed, oneway, layer, |
| 17 | + route_foot, route_cycle, route_motor, access, |
| 18 | + ST_LineMerge(geom) AS geom |
| 19 | + FROM osm.road_line |
| 20 | +), extra_cleanup AS ( |
| 21 | +-- Pull out those that are still multi, use ST_Dump() to pull out parts |
| 22 | +SELECT osm_id, osm_type, maxspeed, oneway, layer, |
| 23 | + route_foot, route_cycle, route_motor, access, |
| 24 | + (ST_Dump(geom)).geom AS geom |
| 25 | + FROM a |
| 26 | + WHERE ST_GeometryType(geom) = 'ST_MultiLineString' |
| 27 | +), combined AS ( |
| 28 | +-- Combine two sources |
| 29 | +SELECT osm_id, osm_type, maxspeed, oneway, layer, |
| 30 | + route_foot, route_cycle, route_motor, access, |
| 31 | + geom |
| 32 | + FROM a |
| 33 | + WHERE ST_GeometryType(geom) != 'ST_MultiLineString' |
| 34 | +UNION |
| 35 | +SELECT osm_id, osm_type, maxspeed, oneway, layer, |
| 36 | + route_foot, route_cycle, route_motor, access, |
| 37 | + geom |
| 38 | + FROM extra_cleanup |
| 39 | + -- Some data may be lost here if multi-linestring somehow |
| 40 | + -- persists through the extra_cleanup query |
| 41 | + WHERE ST_GeometryType(geom) != 'ST_MultiLineString' |
| 42 | +) |
| 43 | +-- Calculate a new surrogate ID for key |
| 44 | +SELECT ROW_NUMBER() OVER (ORDER BY geom) AS id, * |
| 45 | + FROM combined |
| 46 | + ORDER BY geom |
| 47 | +; |
| 48 | +``` |
| 49 | + |
| 50 | +The above query creates the `routing.road_line` table. The next step |
| 51 | +adds some database best practices to the table: |
| 52 | + |
| 53 | +* Explain why a surrogate ID was added |
| 54 | +* Primary key on the `id` column |
| 55 | +* Index on `osm_id` |
| 56 | + |
| 57 | + |
| 58 | +```sql |
| 59 | +COMMENT ON COLUMN routing.road_line.id IS 'Surrogate ID, cannot rely on osm_id being unique after converting multi-linestrings to linestrings.'; |
| 60 | +ALTER TABLE routing.road_line |
| 61 | + ADD CONSTRAINT pk_routing_road_line PRIMARY KEY (id) |
| 62 | +; |
| 63 | +CREATE INDEX ix_routing_road_line_osm_id |
| 64 | + ON routing.road_line (osm_id) |
| 65 | +; |
| 66 | +``` |
| 67 | + |
| 68 | +To prepare the OpenStreetMap roads data for routing with the older pgRouting |
| 69 | +installation, run the |
8 | 70 | pgRouting functions `pgr_nodeNetwork()`, `pgr_createTopology()`, |
9 | 71 | and `pgr_analyzeGraph()`. |
10 | 72 |
|
|
0 commit comments