From 6672f3c4080c6c89ecbb7aca7cce373f31fa7cdd Mon Sep 17 00:00:00 2001 From: MaelReboux Date: Thu, 28 Mar 2019 18:53:10 +0100 Subject: [PATCH] routing second shot --- scripts/create_osm_roads.sh | 70 +++++++++++++++++++++++++++++++++ scripts/create_osm_roads.sql | 2 + scripts/create_tables.sql | 2 + scripts/routing.sql | 49 ++++++++++++++++++++--- scripts/traitements_phase_2.sql | 33 ++++++++++++++-- 5 files changed, 147 insertions(+), 9 deletions(-) create mode 100755 scripts/create_osm_roads.sh diff --git a/scripts/create_osm_roads.sh b/scripts/create_osm_roads.sh new file mode 100755 index 0000000..a5f8618 --- /dev/null +++ b/scripts/create_osm_roads.sh @@ -0,0 +1,70 @@ +#!/bin/sh + + + +# 1. export du tracé depuis la base redadeg + +pg_dump --file data/redadeg_trace.sql --host localhost --username redadeg --no-password --format=p --no-owner --section=pre-data --section=data --no-privileges --no-tablespaces --no-unlogged-table-data --no-comments --table public.phase_1_trace redadeg + + + +# 2. import dans la base OSM + +psql -U osmbr -d osm -c "DROP TABLE public.phase_1_trace;" +psql -U osmbr -d osm < data/redadeg_trace.sql + + + +# 3. calcul de la couche osm_roads = intersection buffer trace et routes OSM + +psql -U osmbr -d osm -c "TRUNCATE TABLE osm_roads ;" +psql -U osmbr -d osm -c "WITH trace_buffer AS ( + SELECT + secteur_id, + ST_Union(ST_Buffer(the_geom, 25, 'quad_segs=2')) AS the_geom + FROM phase_1_trace + GROUP BY secteur_id + ORDER BY secteur_id +) +INSERT INTO osm_roads +( + SELECT + row_number() over() as id, + osm_id, + highway, + CASE + WHEN highway IN ('motorway', 'trunk') THEN 'motorway' + WHEN highway IN ('primary', 'secondary') THEN 'mainroad' + WHEN highway IN ('motorway_link', 'trunk_link', 'primary_link', 'secondary_link', 'tertiary', 'tertiary_link', 'residential', 'unclassified', 'road', 'living_street') THEN 'minorroad' + WHEN highway IN ('service', 'track') THEN 'service' + WHEN highway IN ('path', 'cycleway', 'footway', 'pedestrian', 'steps', 'bridleway') THEN 'noauto' + ELSE 'other' + END AS type, + oneway, + ref, + name AS name_fr, + COALESCE(tags -> 'name:br'::text) as name_br, + ST_Intersection(ST_Transform(o.way,2154), t.the_geom) AS the_geom + FROM planet_osm_line o, trace_buffer t + WHERE highway IS NOT NULL AND ST_INTERSECTS(t.the_geom, ST_Transform(o.way,2154)) +) ;" + + + +# 4. export de osm_roads depuis la base OSM + +pg_dump --file data/osm_roads.sql --host localhost --username osmbr --no-password --format=p --no-owner --section=pre-data --section=data --no-privileges --no-tablespaces --no-unlogged-table-data --no-comments --table public.osm_roads osm + + + +# 5. import dans la base redadeg + +psql -U redadeg -d redadeg -c "DROP TABLE public.phase_1_trace;" +psql -U redadeg -d redadeg < data/redadeg_trace.sql + +psql -U redadeg -d redadeg -c "TRUNCATE TABLE public.osm_roads;" +psql -U redadeg -d redadeg < data/osm_roads.sql + + +echo "fini" + diff --git a/scripts/create_osm_roads.sql b/scripts/create_osm_roads.sql index ade2b0e..8a8f66d 100644 --- a/scripts/create_osm_roads.sql +++ b/scripts/create_osm_roads.sql @@ -22,6 +22,7 @@ -- pg_dump --file redadeg_trace.sql --host localhost --username redadeg --no-password --format=p --no-owner --section=pre-data --section=data --no-privileges --no-tablespaces --no-unlogged-table-data --no-comments --table public.phase_1_trace redadeg -- import dans la base osm +-- psql -U osmbr -d osm -c "DROP TABLE public.phase_1_trace;" -- psql -U osmbr -d osm < redadeg_trace.sql @@ -92,6 +93,7 @@ INSERT INTO osm_roads -- pg_dump --file osm_roads.sql --host localhost --username osmbr --no-password --format=p --no-owner --section=pre-data --section=data --no-privileges --no-tablespaces --no-unlogged-table-data --no-comments --table public.osm_roads osm -- commande d'import +-- psql -U redadeg -d redadeg -c "DROP TABLE public.osm_roads;" -- psql -U redadeg -d redadeg < osm_roads.sql diff --git a/scripts/create_tables.sql b/scripts/create_tables.sql index d3c608e..3fcf5de 100644 --- a/scripts/create_tables.sql +++ b/scripts/create_tables.sql @@ -200,6 +200,8 @@ CREATE TABLE osm_roads_pgr name_br text, source bigint, target bigint, + cost double precision, + reverse_cost double precision, the_geom geometry, CONSTRAINT osm_roads_pgr_pkey PRIMARY KEY (id), CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'LINESTRING'::text OR geometrytype(the_geom) = 'MULTILINESTRING'::text), diff --git a/scripts/routing.sql b/scripts/routing.sql index 628b3bd..4d71afa 100644 --- a/scripts/routing.sql +++ b/scripts/routing.sql @@ -30,6 +30,19 @@ SELECT topology.AddTopoGeometryColumn('osm_roads_topo', 'public', 'osm_roads', ' -- le 2e chiffre est la tolérance en mètres UPDATE osm_roads SET topo_geom = topology.toTopoGeom(the_geom, 'osm_roads_topo', 1, 0.01); +/* +DO $$DECLARE r record; +BEGIN + FOR r IN SELECT * FROM osm_roads LOOP + BEGIN + UPDATE osm_roads SET topo_geom = topology.toTopoGeom(the_geom, 'osm_roads_topo', 1, 0.01); + EXCEPTION + WHEN OTHERS THEN + RAISE WARNING 'Loading of record % failed: %', r.id, SQLERRM; + END; + END LOOP; +END$$; +*/ -- à ce stade on a un graphe topolgique dans le schema osm_roads_topo @@ -37,7 +50,7 @@ UPDATE osm_roads SET topo_geom = topology.toTopoGeom(the_geom, 'osm_roads_topo', -- 4. remplissage de la couche routable depuis la couche d'origine et la topologie INSERT INTO osm_roads_pgr ( SELECT - e.edge_id as id, + row_number() over() as id, o.osm_id, o.highway, o.type, @@ -45,8 +58,10 @@ INSERT INTO osm_roads_pgr o.ref, o.name_fr, o.name_br, - o.source, - o.target, + NULL as source, + NULL as target, + NULL as cost, + NULL as reverse_cost, e.geom as the_geom FROM osm_roads_topo.edge e, osm_roads_topo.relation rel, @@ -55,6 +70,10 @@ WHERE e.edge_id = rel.element_id AND rel.topogeo_id = (o.topo_geom).id ); +-- calcul des 2 attributs de coût (= longueur) +UPDATE osm_roads_pgr SET cost = st_length(the_geom); +UPDATE osm_roads_pgr SET reverse_cost = st_length(the_geom); + -- 5. calcul du graphe routier par pgRouting SELECT pgr_createTopology('osm_roads_pgr', 1.0); @@ -67,10 +86,30 @@ SELECT pgr_nodeNetwork('osm_roads_pgr', 1.0); -- il ne reste plus qu'à faire des calculs d'itinéraires -- test de calcul de plus court chemin SELECT * FROM pgr_dijkstra( - 'SELECT id, source, target, st_length(the_geom) as cost FROM osm_roads_pgr', - 6, 1 + 'SELECT id, source, target, cost, reverse_cost FROM osm_roads_pgr', + 12872, 12810 ); +-- avec la géométrie +SELECT + a.seq AS id, + a.path_seq, + a.node, + a.cost, + a.agg_cost, + b.osm_id, + b.highway, + b.ref, + b.name_fr, + b.name_br, + b.the_geom +FROM pgr_dijkstra( + 'SELECT id, source, target, cost, reverse_cost FROM osm_roads_pgr', + 12872, 12145) as a +JOIN osm_roads_pgr b +ON a.edge = b.id + + -- si besoin : nettoyage par Drop du schéma diff --git a/scripts/traitements_phase_2.sql b/scripts/traitements_phase_2.sql index 788d053..0a8696d 100644 --- a/scripts/traitements_phase_2.sql +++ b/scripts/traitements_phase_2.sql @@ -20,9 +20,9 @@ SELECT topology.AddTopoGeometryColumn('osm_roads_topo', 'public', 'osm_roads', ' -- en remplissant le nouvel attribut géométrique -- le 1er chiffre est l'identifiant du layer dans la table topology.layer -- le 2e chiffre est la tolérance en mètres -UPDATE osm_roads SET topo_geom = topology.toTopoGeom(the_geom, 'osm_roads_topo', 1, 1.0); --- 18 min - +UPDATE osm_roads SET topo_geom = topology.toTopoGeom(the_geom, 'osm_roads_topo', 1, 0.00001); +-- 1.0 = 18 min +-- 0.00001 = 18 min -- à ce stade on a un graphe topologique dans le schema osm_roads_topo @@ -30,9 +30,11 @@ UPDATE osm_roads SET topo_geom = topology.toTopoGeom(the_geom, 'osm_roads_topo', -- 4. remplissage de la couche routable depuis la couche d'origine et la topologie -- on commence par vider avant de remplir TRUNCATE TABLE osm_roads_pgr ; +--TRUNCATE TABLE osm_roads_pgr_noded ; +TRUNCATE TABLE osm_roads_pgr_vertices_pgr ; -- reset des séquences ALTER SEQUENCE osm_roads_pgr_vertices_pgr_id_seq RESTART WITH 1; -ALTER SEQUENCE osm_roads_pgr_noded_id_seq RESTART WITH 1; +--ALTER SEQUENCE osm_roads_pgr_noded_id_seq RESTART WITH 1; INSERT INTO osm_roads_pgr ( SELECT @@ -46,6 +48,8 @@ INSERT INTO osm_roads_pgr o.name_br, NULL as source, NULL as target, + NULL as cost, + NULL as reverse_cost, e.geom as the_geom FROM osm_roads_topo.edge e, osm_roads_topo.relation rel, @@ -54,6 +58,10 @@ WHERE e.edge_id = rel.element_id AND rel.topogeo_id = (o.topo_geom).id ); +-- calcul des 2 attributs de coût (= longueur) +UPDATE osm_roads_pgr SET cost = st_length(the_geom); +UPDATE osm_roads_pgr SET reverse_cost = st_length(the_geom); + -- 5. calcul du graphe routier par pgRouting SELECT pgr_createTopology('osm_roads_pgr', 1.0); @@ -66,6 +74,23 @@ SELECT pgr_nodeNetwork('osm_roads_pgr', 1.0); -- il ne reste plus qu'à faire des calculs d'itinéraires +SELECT + a.seq AS id, + a.path_seq, + a.node, + a.cost, + a.agg_cost, + b.osm_id, + b.highway, + b.ref, + b.name_fr, + b.name_br, + b.the_geom +FROM pgr_dijkstra( + 'SELECT id, source, target, cost, reverse_cost FROM osm_roads_pgr', + 12872, 12145) as a +JOIN osm_roads_pgr b +ON a.edge = b.id