From b706ff638b34a6d631b432533fcc0366b10a358b Mon Sep 17 00:00:00 2001 From: MaelReboux Date: Sun, 19 May 2019 11:23:00 +0200 Subject: [PATCH] Gestion des zones de boucles --- scripts/create_tables.sql | 39 +++++++++++++++++++++++++++++---- scripts/patch_osm_roads_pgr.sql | 33 ++++++++++++++++++++++++++++ scripts/traitements_phase_2.sh | 8 +++++++ 3 files changed, 76 insertions(+), 4 deletions(-) create mode 100644 scripts/patch_osm_roads_pgr.sql diff --git a/scripts/create_tables.sql b/scripts/create_tables.sql index 043982c..3ec8b7b 100644 --- a/scripts/create_tables.sql +++ b/scripts/create_tables.sql @@ -257,12 +257,43 @@ CREATE TABLE phase_2_point_nettoyage ALTER TABLE phase_2_point_nettoyage OWNER to redadeg; --- dans la base redadeg on chargera la couche osm_roads qui a été calculée --- à partir de données OSM +-- couche de polygones pour supprimer le contenu de osm_roads_pgr pour la gestion des boucles +DROP TABLE IF EXISTS osm_roads_pgr_patch_mask ; +CREATE TABLE osm_roads_mask +( + id serial, + name text, + the_geom geometry, + CONSTRAINT osm_roads_pgr_patch_mask_pkid PRIMARY KEY (id), + CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'POLYGON'::text), + CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 2154) +); +ALTER TABLE osm_roads_pgr_patch_mask OWNER to redadeg; --- 1. création d'un schéma qui va accueillir le réseau topologique de la couche osm_roads -SELECT topology.CreateTopology('osm_roads_topo', 2154); +-- couche jumelle de osm_roads mais avec des lignes gérées à la main pour les boucles +DROP TABLE IF EXISTS osm_roads_pgr_patch ; +CREATE TABLE osm_roads_pgr_patch +( + id serial, + osm_id bigint, + highway text, + type text, + oneway text, + ref text, + name_fr text, + name_br text, + source bigint, + target bigint, + cost double precision, + reverse_cost double precision, + the_geom geometry, + CONSTRAINT osm_roads_pgr_patch_pkey PRIMARY KEY (id), + CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'LINESTRING'::text OR geometrytype(the_geom) = 'MULTILINESTRING'::text), + CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 2154) +); +ALTER TABLE osm_roads_pgr_patch OWNER to redadeg; + -- la table qui va recevoir le résultat du calcul d'itinéraire diff --git a/scripts/patch_osm_roads_pgr.sql b/scripts/patch_osm_roads_pgr.sql new file mode 100644 index 0000000..0cc1e3e --- /dev/null +++ b/scripts/patch_osm_roads_pgr.sql @@ -0,0 +1,33 @@ + + + + + +-- suppression des objets couche osm_roads_pgr qui intersectent avec les zones de boucles +DELETE FROM osm_roads_pgr WHERE id IN +( + SELECT a.id + FROM osm_roads_pgr a, osm_roads_pgr_patch_mask m + WHERE ST_INTERSECTS(a.the_geom, m.the_geom) +); + +-- collage des objets de la couche osm_roads_pgr_patch à la place des objets supprimés +INSERT INTO osm_roads_pgr + SELECT + 0-a.id AS id, + a.osm_id, a.highway, a.type, a.oneway, a.ref, a.name_fr, a.name_br, + NULL, NULL, NULL, NULL, + a.the_geom + FROM osm_roads_pgr_patch a, osm_roads_pgr_patch_mask m + WHERE ST_INTERSECTS(a.the_geom, m.the_geom); + + +-- calcul des 2 attributs de coût (= longueur) +UPDATE osm_roads_pgr +SET cost = st_length(the_geom), reverse_cost = st_length(the_geom) +WHERE id < 0 ; + + +-- calcul de la topologie pgRouting sur les zones de masque +SELECT pgr_createTopology('osm_roads_pgr', 0.001, 'the_geom', 'id', 'source', 'target', rows_where := 'id < 0', clean := false); + diff --git a/scripts/traitements_phase_2.sh b/scripts/traitements_phase_2.sh index fa679a6..62a77aa 100755 --- a/scripts/traitements_phase_2.sh +++ b/scripts/traitements_phase_2.sh @@ -84,6 +84,14 @@ echo " fait" echo "nettoyage de la couche de routage par les points ciblés" $PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME -c "UPDATE osm_roads_pgr SET cost = 1000000, reverse_cost = 1000000 WHERE id IN (SELECT r.id FROM osm_roads_pgr r JOIN phase_2_point_nettoyage p ON r.id = p.edge_id);" echo " fait" +echo "" + + +# patch de la couche de routage sur les zones de boucles +echo "patch de la couche de routage sur les zones de boucles" +$PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME < patch_osm_roads_pgr.sql +echo " fait" +echo "" # on fait la requête qui va donner une liste de PK de secteurs