suppression du répertoire v1 des scripts
This commit is contained in:
parent
27aee83173
commit
b864017955
|
@ -1,71 +0,0 @@
|
|||
#!/bin/bash
|
||||
|
||||
cd /data/www/vhosts/ar-redadeg_openstreetmap_bzh/htdocs/scripts/backup/
|
||||
#cd backup/
|
||||
|
||||
# ++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++
|
||||
# on récupère les couches geojson depuis umap pour sauvegarde au cas où
|
||||
|
||||
# carte phase 1
|
||||
# le tracé manuel
|
||||
#curl -sS http://umap.openstreetmap.fr/fr/datalayer/746021/ > "phase_1/$(date +%Y%m%d)_$(date +%H%M)_phase_1_trace.geojson"
|
||||
# PK VIP
|
||||
#curl -sS http://umap.openstreetmap.fr/fr/datalayer/715179/ > "phase_1/$(date +%Y%m%d)_$(date +%H%M)_phase_1_pk_vip.geojson"
|
||||
|
||||
|
||||
# carte phase 2
|
||||
# PK secteur
|
||||
#curl -sS http://umap.openstreetmap.fr/fr/datalayer/817220/ > "phase_2/$(date +%Y%m%d)_$(date +%H%M)_phase_2_pk_secteur.geojson"
|
||||
# PK technique / PK tecknikel
|
||||
#curl -sS http://umap.openstreetmap.fr/fr/datalayer/817221/ > "phase_2/$(date +%Y%m%d)_$(date +%H%M)_phase_2_pk_techniques.geojson"
|
||||
# points coupe tracé
|
||||
#curl -sS http://umap.openstreetmap.fr/fr/datalayer/861810/ > "phase_2/$(date +%Y%m%d)_$(date +%H%M)_phase_2_points_coupe_trace.geoson"
|
||||
|
||||
|
||||
# on remonte d'un niveau ceux cd 06h 13h et 18h
|
||||
|
||||
# si le nom du fichier matche le motif regexp
|
||||
# on copie le fichier dans un autre répertoire
|
||||
|
||||
# for f in jour_courant/*.geojson
|
||||
# do
|
||||
# #if [[ $f =~ [0-9]{8}_(0600|1300|1800)_* ]]
|
||||
# if [[ $f =~ [0-9]{8}_(1200)_* ]]
|
||||
# then cp $f ./
|
||||
# fi
|
||||
# done
|
||||
|
||||
|
||||
# ++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++
|
||||
|
||||
# cartes phase 5
|
||||
|
||||
# on sauvegarde les couches de PK gérés manuellement par secteurs
|
||||
# secteur 1
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/1027042/ > "phase_5/phase_5_pk_secteur_01_$(date +%Y%m%d)_$(date +%H%M).geojson"
|
||||
# secteur 2
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/1027081/ > "phase_5/phase_5_pk_secteur_02_$(date +%Y%m%d)_$(date +%H%M).geojson"
|
||||
# secteur 3
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/1027101/ > "phase_5/phase_5_pk_secteur_03_$(date +%Y%m%d)_$(date +%H%M).geojson"
|
||||
# secteur 4
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/1027104/ > "phase_5/phase_5_pk_secteur_04_$(date +%Y%m%d)_$(date +%H%M).geojson"
|
||||
# secteur 5
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/1027107/ > "phase_5/phase_5_pk_secteur_05_$(date +%Y%m%d)_$(date +%H%M).geojson"
|
||||
# secteur 6
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/1027110/ > "phase_5/phase_5_pk_secteur_06_$(date +%Y%m%d)_$(date +%H%M).geojson"
|
||||
# secteur 7
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/1027114/ > "phase_5/phase_5_pk_secteur_07_$(date +%Y%m%d)_$(date +%H%M).geojson"
|
||||
# secteur 8
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/1027117/ > "phase_5/phase_5_pk_secteur_08_$(date +%Y%m%d)_$(date +%H%M).geojson"
|
||||
# secteur 9
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/1027120/ > "phase_5/phase_5_pk_secteur_09_$(date +%Y%m%d)_$(date +%H%M).geojson"
|
||||
# secteur 10
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/1027123/ > "phase_5/phase_5_pk_secteur_10_$(date +%Y%m%d)_$(date +%H%M).geojson"
|
||||
|
||||
|
||||
# la couche des PK assemblés
|
||||
cp ../data/phase_5_pk.geojson "phase_5/phase_5_pk_$(date +%Y%m%d)_$(date +%H%M).geojson"
|
||||
|
||||
|
||||
|
||||
|
|
@ -1,8 +0,0 @@
|
|||
|
||||
[pg_redadeg]
|
||||
host = bed110.bedniverel.bzh
|
||||
port = 55432
|
||||
db = redadeg
|
||||
schema = public
|
||||
user = redadeg
|
||||
passwd = redadeg
|
|
@ -1,52 +0,0 @@
|
|||
#!/bin/bash
|
||||
|
||||
# exit dès que qqch se passe mal
|
||||
#set -e
|
||||
# ?
|
||||
set -u
|
||||
|
||||
# utiliser un compte SUPERUSER pour exécuter ce script
|
||||
|
||||
# argument 1 = millesime redadeg
|
||||
millesime=$1
|
||||
|
||||
PSQL=/usr/bin/psql
|
||||
DB_HOST=localhost
|
||||
DB_NAME=redadeg_$millesime
|
||||
|
||||
|
||||
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " Création de la base de données $DB_NAME"
|
||||
echo ""
|
||||
echo ""
|
||||
|
||||
|
||||
echo "La base de données $DB_NAME va être supprimée !!"
|
||||
|
||||
if [ ! -t 0 ]; then x-terminal-emulator -e "$0"; exit 0; fi
|
||||
read -r -p "Appuyer sur n'importe quelle touche pour continuer..." key
|
||||
|
||||
# suppression de la base de données existantes
|
||||
echo "DROP DATABASE $DB_NAME ;" | psql -U postgres -w
|
||||
|
||||
# create role
|
||||
psql -h $DB_HOST -d postgres -c "CREATE USER redadeg WITH PASSWORD 'redadeg' SUPERUSER;"
|
||||
|
||||
# create database with owner redadeg
|
||||
psql -h $DB_HOST -d postgres -c "CREATE DATABASE $DB_NAME WITH OWNER = redadeg ENCODING = 'UTF8';"
|
||||
|
||||
# extensions postgis
|
||||
psql -h $DB_HOST -d $DB_NAME -c "CREATE EXTENSION postgis;"
|
||||
psql -h $DB_HOST -d $DB_NAME -c "CREATE EXTENSION postgis_topology;"
|
||||
psql -h $DB_HOST -d $DB_NAME -c "CREATE EXTENSION pgrouting;"
|
||||
|
||||
# permissions
|
||||
psql -h $DB_HOST -d $DB_NAME -c "ALTER SCHEMA public OWNER TO redadeg;"
|
||||
psql -h $DB_HOST -d $DB_NAME -c "ALTER TABLE topology.layer OWNER TO redadeg ;"
|
||||
psql -h $DB_HOST -d $DB_NAME -c "ALTER TABLE topology.topology OWNER TO redadeg ;"
|
||||
|
||||
# vérifications
|
||||
psql -h $DB_HOST -d $DB_NAME -c "SELECT * FROM postgis_version();"
|
||||
psql -h $DB_HOST -d $DB_NAME -c "SELECT * FROM pgr_version();"
|
||||
|
|
@ -1,136 +0,0 @@
|
|||
#!/bin/bash
|
||||
|
||||
set -e
|
||||
set -u
|
||||
|
||||
# argument 1 = millesime redadeg
|
||||
millesime=$1
|
||||
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " Création de la couche osm_roads"
|
||||
echo ""
|
||||
echo ""
|
||||
|
||||
PSQL=/usr/bin/psql
|
||||
HOST_DB_redadeg=localhost
|
||||
HOST_DB_osm=localhost
|
||||
DB_REDADEG=redadeg_$millesime
|
||||
DB_OSM=osm
|
||||
DB_USER=redadeg
|
||||
DB_PASSWD=redadeg
|
||||
|
||||
rep_scripts='/data/projets/ar_redadeg/scripts/'
|
||||
echo "rep_scripts = $rep_scripts"
|
||||
# variables liées au millésimes
|
||||
echo "millesime de travail = $1"
|
||||
rep_data=../data/$millesime
|
||||
echo "rep_data = $rep_data"
|
||||
|
||||
echo ""
|
||||
echo "import phase_1_trace dans la base OSM"
|
||||
echo ""
|
||||
|
||||
# 1. export du tracé phase 1 depuis la base redadeg
|
||||
pg_dump --dbname=postgresql://$DB_USER:$DB_PASSWD@$HOST_DB_redadeg/$DB_REDADEG \
|
||||
--format=p --no-owner --section=pre-data --section=data --no-privileges --no-tablespaces --no-unlogged-table-data --no-comments \
|
||||
--table phase_1_trace \
|
||||
--file $rep_data/redadeg_trace.sql
|
||||
|
||||
|
||||
# 2. import dans la base OSM
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $HOST_DB_osm -U $DB_USER -d $DB_OSM -c "DROP TABLE IF EXISTS phase_1_trace_$millesime ;"
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $HOST_DB_osm -U $DB_USER -d $DB_OSM < $rep_data/redadeg_trace.sql
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $HOST_DB_osm -U $DB_USER -d $DB_OSM -c "ALTER TABLE phase_1_trace RENAME TO phase_1_trace_$millesime ;"
|
||||
|
||||
echo ""
|
||||
echo "fait"
|
||||
echo ""
|
||||
|
||||
|
||||
# 3. calcul de la couche osm_roads = intersection buffer trace et routes OSM
|
||||
|
||||
echo ">> calcul de la couche osm_roads"
|
||||
echo ""
|
||||
|
||||
# on supprime puis on recrée la table
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $HOST_DB_osm -U $DB_USER -d $DB_OSM -c "DROP TABLE IF EXISTS osm_roads_$millesime ;"
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $HOST_DB_osm -U $DB_USER -d $DB_OSM -c "
|
||||
CREATE TABLE osm_roads_$millesime
|
||||
(
|
||||
uid bigint NOT NULL,
|
||||
osm_id bigint,
|
||||
highway text,
|
||||
type text,
|
||||
oneway text,
|
||||
ref text,
|
||||
name_fr text,
|
||||
name_br text,
|
||||
the_geom geometry,
|
||||
CONSTRAINT osm_roads_pkey PRIMARY KEY (uid),
|
||||
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)
|
||||
);"
|
||||
|
||||
echo ""
|
||||
echo " table osm_roads_$millesime créée"
|
||||
echo ""
|
||||
echo " extraction du filaire de voies OSM le long du tracé fourni"
|
||||
echo ""
|
||||
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $HOST_DB_osm -U $DB_USER -d $DB_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_$millesime
|
||||
GROUP BY secteur_id
|
||||
ORDER BY secteur_id
|
||||
)
|
||||
INSERT INTO osm_roads_$millesime
|
||||
(
|
||||
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))
|
||||
) ;"
|
||||
|
||||
echo ""
|
||||
echo "fait"
|
||||
echo ""
|
||||
|
||||
|
||||
# 4. export de osm_roads depuis la base OSM
|
||||
|
||||
echo "transfert de osm_roads_$millesime depuis la base OSM vers la base redadeg"
|
||||
echo ""
|
||||
|
||||
pg_dump --dbname=postgresql://$DB_USER:$DB_PASSWD@$HOST_DB_osm/$DB_OSM \
|
||||
--format=p --no-owner --section=pre-data --section=data --no-privileges --no-tablespaces --no-unlogged-table-data --no-comments \
|
||||
--table osm_roads_$millesime \
|
||||
--file $rep_data/osm_roads.sql
|
||||
|
||||
# 5. import dans la base redadeg
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $HOST_DB_redadeg -U $DB_USER -d $DB_REDADEG -c "DROP TABLE IF EXISTS osm_roads;"
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $HOST_DB_redadeg -U $DB_USER -d $DB_REDADEG < $rep_data/osm_roads.sql
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $HOST_DB_redadeg -U $DB_USER -d $DB_REDADEG -c "ALTER TABLE osm_roads_$millesime RENAME TO osm_roads ;"
|
||||
|
||||
echo ""
|
||||
echo "fait"
|
||||
echo ""
|
||||
|
||||
echo "fini"
|
||||
|
|
@ -1,101 +0,0 @@
|
|||
/*
|
||||
==========================================================================
|
||||
|
||||
OpenStreetMap : création de la couche du réseau routier OSM
|
||||
pour le calcul d'itinéraires
|
||||
|
||||
==========================================================================
|
||||
*/
|
||||
|
||||
-- A faire dans une base OSM contenant un import osm2pgsql
|
||||
|
||||
-- Le but est de créer une table osm_roads qui contiendra
|
||||
-- le réseau routier dans une zone-tampon de 500 autour du tracé.
|
||||
|
||||
-- on fait ça dans une base à part à cause de la volumétrie des données OSM
|
||||
|
||||
|
||||
|
||||
-- 1. import du tracé dans la base OSM
|
||||
|
||||
-- export du tracé depuis la base redadeg
|
||||
-- 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
|
||||
|
||||
|
||||
|
||||
|
||||
-- 2. création de la table qui va accueillir les tronçons de routes
|
||||
|
||||
-- la table qui contient le graphe routier de OSM
|
||||
DROP TABLE IF EXISTS osm_roads ;
|
||||
CREATE TABLE osm_roads
|
||||
(
|
||||
uid bigint,
|
||||
osm_id bigint,
|
||||
highway text,
|
||||
type text,
|
||||
oneway text,
|
||||
ref text,
|
||||
name_fr text,
|
||||
name_br text,
|
||||
the_geom geometry,
|
||||
CONSTRAINT osm_roads_pkey PRIMARY KEY (uid),
|
||||
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)
|
||||
);
|
||||
|
||||
|
||||
|
||||
-- 3. remplissage de la table à l'aide d'un requête
|
||||
-- qui va faire un buffer de 25 m autour du tracé
|
||||
-- environ 5 min de traitement
|
||||
|
||||
TRUNCATE TABLE osm_roads ;
|
||||
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. on l'exporte pour la recharger dans la base redadeg
|
||||
|
||||
-- commande d'export
|
||||
-- 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
|
||||
|
||||
|
||||
|
||||
|
|
@ -1,44 +0,0 @@
|
|||
#!/bin/bash
|
||||
|
||||
set -e
|
||||
set -u
|
||||
|
||||
# argument 1 = millesime redadeg
|
||||
millesime=$1
|
||||
|
||||
PSQL=/usr/bin/psql
|
||||
DB_HOST=localhost
|
||||
DB_NAME=redadeg_$millesime
|
||||
DB_USER=redadeg
|
||||
DB_PASSWD=redadeg
|
||||
|
||||
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " Création de la couche osm_roads_pgr"
|
||||
echo ""
|
||||
echo ""
|
||||
|
||||
# suppose le le .pgpass est correctement configuré pour le compte qui lance ce script
|
||||
|
||||
|
||||
echo ">> suppression de la topologie existante"
|
||||
echo ""
|
||||
$PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME -c "SELECT DropTopology('osm_roads_topo') ;" || true
|
||||
echo ""
|
||||
|
||||
# création d'un schéma qui va accueillir le réseau topologique de la couche osm_roads
|
||||
echo ">> création d'une nouvelle topologie"
|
||||
echo ""
|
||||
$PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME -c "SELECT topology.CreateTopology('osm_roads_topo', 2154);"
|
||||
|
||||
|
||||
echo ">> ajout d'un nouvel attribut sur la table osm_roads"
|
||||
echo ""
|
||||
$PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME -c "SELECT topology.AddTopoGeometryColumn('osm_roads_topo', 'public', 'osm_roads', 'topo_geom', 'LINESTRING');"
|
||||
echo ""
|
||||
echo "fait"
|
||||
echo ""
|
||||
|
||||
|
||||
echo "fini >> exécuter update_osm_roads_pgr.sh "
|
||||
echo ""
|
|
@ -1,29 +0,0 @@
|
|||
#!/bin/bash
|
||||
|
||||
set -e
|
||||
set -u
|
||||
|
||||
# argument 1 = millesime redadeg
|
||||
millesime=$1
|
||||
|
||||
PSQL=/usr/bin/psql
|
||||
DB_HOST=localhost
|
||||
DB_NAME=redadeg_$millesime
|
||||
DB_USER=redadeg
|
||||
DB_PASSWD=redadeg
|
||||
|
||||
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " Création des tables dans la base de données $DB_NAME"
|
||||
echo ""
|
||||
echo ""
|
||||
|
||||
# suppression d'abord
|
||||
psql -h $DB_HOST -U redadeg -d $DB_NAME < drop_tables.sql
|
||||
|
||||
# création
|
||||
psql -h $DB_HOST -U redadeg -d $DB_NAME < create_tables.sql
|
||||
|
||||
# initialisation de la table de référence des secteurs pour le millésime
|
||||
psql -h $DB_HOST -U redadeg -d $DB_NAME < ../data/$millesime/update_infos_secteurs.sql
|
||||
|
|
@ -1,755 +0,0 @@
|
|||
|
||||
|
||||
/*
|
||||
==========================================================================
|
||||
|
||||
phase 1 : récupération des données depuis umap et calcul des PK auto
|
||||
|
||||
==========================================================================
|
||||
*/
|
||||
|
||||
-- voir la documentation pour la création de la base de données
|
||||
|
||||
-- on est obligé de créer des tables en Lambert 93 (EPSG:2154) (ou une CC conforme)
|
||||
-- car même si les tables originales sont déclarées en 3857
|
||||
-- en fait les géoémtries sont en 4326
|
||||
-- donc les calculs de longueur sont faux
|
||||
-- au moins en créant une table en dur en Lambert 93 / 2154 on est sûr des longueurs
|
||||
|
||||
|
||||
-- la table secteur gère les grands découpage de gestion
|
||||
DROP TABLE IF EXISTS secteur CASCADE ;
|
||||
CREATE TABLE secteur
|
||||
(
|
||||
id integer,
|
||||
nom_br text,
|
||||
nom_fr text,
|
||||
objectif_km integer,
|
||||
km_redadeg integer
|
||||
);
|
||||
|
||||
ALTER TABLE secteur OWNER to redadeg;
|
||||
|
||||
|
||||
|
||||
DROP TABLE IF EXISTS phase_1_trace_3857 ;
|
||||
CREATE TABLE phase_1_trace_3857
|
||||
(
|
||||
fake_column integer
|
||||
);
|
||||
ALTER TABLE phase_1_trace_3857 OWNER to redadeg;
|
||||
|
||||
DROP TABLE IF EXISTS phase_1_pk_vip_3857 ;
|
||||
CREATE TABLE phase_1_pk_vip_3857
|
||||
(
|
||||
fake_column integer
|
||||
);
|
||||
ALTER TABLE phase_1_pk_vip_3857 OWNER to redadeg;
|
||||
|
||||
|
||||
|
||||
DROP TABLE IF EXISTS phase_1_trace CASCADE ;
|
||||
CREATE TABLE phase_1_trace
|
||||
(
|
||||
ogc_fid integer,
|
||||
secteur_id int,
|
||||
ordre int,
|
||||
longueur numeric,
|
||||
the_geom geometry(LineString,2154),
|
||||
CONSTRAINT phase_1_trace_pkey PRIMARY KEY (ogc_fid),
|
||||
CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'LINESTRING'::text),
|
||||
CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 2154)
|
||||
);
|
||||
ALTER TABLE phase_1_trace OWNER to redadeg;
|
||||
|
||||
|
||||
DROP TABLE IF EXISTS phase_1_pk_vip CASCADE ;
|
||||
CREATE TABLE phase_1_pk_vip
|
||||
(
|
||||
ogc_fid integer,
|
||||
name text,
|
||||
description text,
|
||||
the_geom geometry(Point,2154),
|
||||
CONSTRAINT phase_1_pk_vip_pkey PRIMARY KEY (ogc_fid),
|
||||
CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'POINT'::text),
|
||||
CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 2154)
|
||||
);
|
||||
ALTER TABLE phase_1_pk_vip OWNER to redadeg;
|
||||
|
||||
|
||||
-- on crée aussi une version correcte en 4326 pour export vers umap
|
||||
DROP TABLE IF EXISTS phase_1_trace_4326 ;
|
||||
CREATE TABLE phase_1_trace_4326
|
||||
(
|
||||
ogc_fid integer,
|
||||
name text, -- = section_nom
|
||||
secteur_id int,
|
||||
ordre int,
|
||||
longueur numeric,
|
||||
the_geom geometry(LineString,4326),
|
||||
CONSTRAINT phase_1_trace_4326_pkey PRIMARY KEY (ogc_fid),
|
||||
CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'LINESTRING'::text),
|
||||
CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 4326)
|
||||
);
|
||||
ALTER TABLE phase_1_trace_4326 OWNER to redadeg;
|
||||
|
||||
|
||||
-- table des tronçons créés à partir des longs tracés
|
||||
DROP TABLE IF EXISTS phase_1_trace_troncons CASCADE ;
|
||||
CREATE TABLE phase_1_trace_troncons
|
||||
(
|
||||
uid bigint,
|
||||
secteur_id int,
|
||||
ordre bigint,
|
||||
km bigint,
|
||||
km_reel bigint,
|
||||
longueur integer,
|
||||
the_geom geometry(LineString,2154),
|
||||
CONSTRAINT phase_1_trace_troncons_pkey PRIMARY KEY (uid),
|
||||
CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'LINESTRING'::text),
|
||||
CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 2154)
|
||||
);
|
||||
ALTER TABLE phase_1_trace_troncons OWNER to redadeg;
|
||||
|
||||
|
||||
|
||||
-- vue des PK auto en fin de tronçon
|
||||
DROP VIEW IF EXISTS phase_1_pk_auto ;
|
||||
CREATE VIEW phase_1_pk_auto AS
|
||||
SELECT
|
||||
uid, secteur_id, ordre, km, km_reel,
|
||||
ST_Line_Interpolate_Point(the_geom, 1)::geometry(Point, 2154) AS the_geom
|
||||
FROM phase_1_trace_troncons
|
||||
ORDER BY secteur_id ASC, ordre ASC, km ASC ;
|
||||
ALTER TABLE phase_1_pk_auto OWNER to redadeg;
|
||||
|
||||
-- la même mais en 4326 pour export
|
||||
DROP VIEW IF EXISTS phase_1_pk_auto_4326 ;
|
||||
CREATE VIEW phase_1_pk_auto_4326 AS
|
||||
SELECT
|
||||
uid, secteur_id, ordre, km, km_reel,
|
||||
ST_Transform(the_geom,4326)::geometry(Point, 4326) AS the_geom
|
||||
FROM phase_1_pk_auto
|
||||
ORDER BY secteur_id ASC, ordre ASC, km ASC ;
|
||||
ALTER TABLE phase_1_pk_auto_4326 OWNER to redadeg;
|
||||
|
||||
-- vue tableau de bord de synthèse
|
||||
DROP VIEW IF EXISTS phase_1_tdb ;
|
||||
CREATE VIEW phase_1_tdb AS
|
||||
SELECT
|
||||
t.secteur_id, s.nom_br, s.nom_fr,
|
||||
TRUNC( SUM(t.longueur)::numeric , 3) AS longueur_km,
|
||||
ROUND( SUM(t.longueur)::numeric ) AS longueur_km_arrondi
|
||||
FROM phase_1_trace t JOIN secteur s ON t.secteur_id = s.id
|
||||
GROUP BY secteur_id, nom_br, nom_fr
|
||||
ORDER BY secteur_id ;
|
||||
ALTER TABLE phase_1_tdb OWNER to redadeg;
|
||||
|
||||
|
||||
|
||||
|
||||
/*
|
||||
==========================================================================
|
||||
|
||||
phase 2 : calcul d'itinéraires en appui du réseau routier OSM
|
||||
|
||||
==========================================================================
|
||||
*/
|
||||
|
||||
-- les couches PK venant de umap
|
||||
|
||||
DROP TABLE IF EXISTS phase_2_pk_secteur_3857 ;
|
||||
CREATE TABLE phase_2_pk_secteur_3857
|
||||
(
|
||||
fake_column integer
|
||||
);
|
||||
ALTER TABLE phase_2_pk_secteur_3857 OWNER to redadeg;
|
||||
|
||||
DROP TABLE IF EXISTS phase_2_point_nettoyage_3857 ;
|
||||
CREATE TABLE phase_2_point_nettoyage_3857
|
||||
(
|
||||
fake_column integer
|
||||
);
|
||||
ALTER TABLE phase_2_point_nettoyage_3857 OWNER to redadeg;
|
||||
|
||||
|
||||
DROP TABLE IF EXISTS phase_2_pk_secteur CASCADE ;
|
||||
CREATE TABLE phase_2_pk_secteur
|
||||
(
|
||||
id integer,
|
||||
name text,
|
||||
pgr_node_id integer,
|
||||
secteur_id integer,
|
||||
the_geom geometry(Point,2154),
|
||||
CONSTRAINT phase_2_pk_secteur_pkey PRIMARY KEY (id),
|
||||
CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'POINT'::text),
|
||||
CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 2154)
|
||||
);
|
||||
ALTER TABLE phase_2_pk_secteur OWNER to redadeg;
|
||||
|
||||
|
||||
-- une vue en 4326 pour export
|
||||
DROP VIEW IF EXISTS phase_2_pk_secteur_4326 CASCADE ;
|
||||
CREATE VIEW phase_2_pk_secteur_4326 AS
|
||||
SELECT
|
||||
pk.id, pk.name, s.id AS secteur_id, replace(s.nom_fr,' ','') AS nom_fr, replace(s.nom_br,' ','') AS nom_br,
|
||||
ST_Transform(pk.the_geom,4326)::geometry(Point, 4326) AS the_geom
|
||||
FROM phase_2_pk_secteur pk JOIN secteur s ON pk.id = s.id
|
||||
ORDER BY pk.id ;
|
||||
ALTER TABLE phase_2_pk_secteur_4326 OWNER to redadeg;
|
||||
|
||||
|
||||
-- les polygones des communes source OSM France
|
||||
DROP TABLE IF EXISTS osm_communes CASCADE ;
|
||||
CREATE TABLE osm_communes
|
||||
(
|
||||
gid serial,
|
||||
insee character varying(80),
|
||||
nom character varying(80),
|
||||
wikipedia character varying(80),
|
||||
surf_ha numeric,
|
||||
the_geom geometry,
|
||||
CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'POLYGON'::text OR geometrytype(the_geom) = 'MULTIPOLYGON'::text),
|
||||
CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 2154),
|
||||
CONSTRAINT osm_communes_pkey PRIMARY KEY (gid)
|
||||
);
|
||||
CREATE INDEX osm_communes_geom_idx ON osm_communes USING gist(the_geom);
|
||||
ALTER TABLE osm_communes OWNER to redadeg;
|
||||
|
||||
|
||||
-- la couche avec les info langue minoritaire
|
||||
DROP TABLE IF EXISTS osm_municipalities CASCADE ;
|
||||
CREATE TABLE osm_municipalities
|
||||
(
|
||||
id serial,
|
||||
osm_id bigint,
|
||||
type text,
|
||||
admin_level text,
|
||||
name text,
|
||||
name_fr text,
|
||||
name_br text,
|
||||
source_name_br text,
|
||||
admincode text,
|
||||
postcode text,
|
||||
wikidata text,
|
||||
surf_ha numeric,
|
||||
x numeric,
|
||||
y numeric,
|
||||
the_geom geometry,
|
||||
CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'POLYGON'::text OR geometrytype(the_geom) = 'MULTIPOLYGON'::text),
|
||||
CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 2154),
|
||||
CONSTRAINT osm_municipalities_pkey PRIMARY KEY (id)
|
||||
);
|
||||
CREATE INDEX osm_municipalities_geom_idx ON osm_municipalities USING gist(the_geom);
|
||||
CREATE INDEX osm_municipalities_admincode_idx ON osm_municipalities(admincode);
|
||||
ALTER TABLE osm_municipalities OWNER to redadeg;
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
-- la couche qui contient les lignes des routes venant de OSM
|
||||
DROP TABLE IF EXISTS osm_roads CASCADE ;
|
||||
CREATE TABLE osm_roads
|
||||
(
|
||||
uid bigint NOT NULL,
|
||||
osm_id bigint,
|
||||
highway text,
|
||||
type text,
|
||||
oneway text,
|
||||
ref text,
|
||||
name_fr text,
|
||||
name_br text,
|
||||
the_geom geometry,
|
||||
CONSTRAINT osm_roads_pkey PRIMARY KEY (uid),
|
||||
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)
|
||||
);
|
||||
CREATE INDEX osm_roads_geom_idx ON osm_roads USING gist(the_geom);
|
||||
ALTER TABLE osm_roads OWNER to redadeg;
|
||||
|
||||
|
||||
-- la couche en version routable
|
||||
DROP TABLE IF EXISTS osm_roads_pgr CASCADE ;
|
||||
CREATE TABLE osm_roads_pgr
|
||||
(
|
||||
id bigint,
|
||||
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_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)
|
||||
);
|
||||
CREATE INDEX osm_roads_pgr_source_idx ON osm_roads_pgr (source);
|
||||
CREATE INDEX osm_roads_pgr_target_idx ON osm_roads_pgr (target);
|
||||
ALTER TABLE osm_roads_pgr OWNER to redadeg;
|
||||
|
||||
|
||||
-- la couche des points pour nettoyer la couche de routage
|
||||
DROP TABLE IF EXISTS phase_2_point_nettoyage CASCADE ;
|
||||
CREATE TABLE phase_2_point_nettoyage
|
||||
(
|
||||
id serial,
|
||||
pt_id bigint,
|
||||
edge_id bigint,
|
||||
distance numeric,
|
||||
the_geom geometry,
|
||||
CONSTRAINT phase_2_point_nettoyage_pkey PRIMARY KEY (id),
|
||||
CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'POINT'::text),
|
||||
CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 2154)
|
||||
);
|
||||
ALTER TABLE phase_2_point_nettoyage OWNER to redadeg;
|
||||
|
||||
|
||||
-- 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 CASCADE ;
|
||||
CREATE TABLE osm_roads_pgr_patch_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;
|
||||
|
||||
|
||||
-- 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 CASCADE ;
|
||||
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 séquence doit commencer à un chiffre supérieur à 1 car sinon ça fiche la pagaille sur le calcul de routage
|
||||
ALTER SEQUENCE osm_roads_pgr_patch_id_seq START WITH 1000 ;
|
||||
|
||||
|
||||
|
||||
-- la table qui va recevoir le résultat du calcul d'itinéraire
|
||||
DROP TABLE IF EXISTS phase_2_trace_pgr CASCADE ;
|
||||
CREATE TABLE phase_2_trace_pgr
|
||||
(
|
||||
secteur_id integer,
|
||||
-- info de routage
|
||||
path_seq bigint,
|
||||
node bigint,
|
||||
cost double precision,
|
||||
agg_cost double precision,
|
||||
-- info OSM
|
||||
osm_id bigint,
|
||||
highway text,
|
||||
type text,
|
||||
oneway text,
|
||||
ref text,
|
||||
name_fr text,
|
||||
name_br text,
|
||||
the_geom geometry,
|
||||
--CONSTRAINT phase_2_trace_pkey PRIMARY KEY (secteur_id, path_seq),
|
||||
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 phase_2_trace_pgr OWNER to redadeg;
|
||||
|
||||
-- une vue en 4326 pour export
|
||||
DROP VIEW IF EXISTS phase_2_trace_pgr_4326 ;
|
||||
CREATE VIEW phase_2_trace_pgr_4326 AS
|
||||
SELECT
|
||||
secteur_id,
|
||||
path_seq, node, cost, agg_cost,
|
||||
osm_id, highway, type, oneway, ref, name_fr, name_br,
|
||||
ST_Transform(the_geom,4326)::geometry(LineString, 4326) AS the_geom
|
||||
FROM phase_2_trace_pgr ;
|
||||
ALTER TABLE phase_2_trace_pgr_4326 OWNER to redadeg;
|
||||
|
||||
|
||||
|
||||
-- couche qui contient 1 ligne par secteur
|
||||
DROP TABLE IF EXISTS phase_2_trace_secteur CASCADE ;
|
||||
CREATE TABLE phase_2_trace_secteur
|
||||
(
|
||||
secteur_id int,
|
||||
nom_fr text,
|
||||
nom_br text,
|
||||
longueur int,
|
||||
longueur_km numeric,
|
||||
the_geom geometry,
|
||||
CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 2154)
|
||||
);
|
||||
ALTER TABLE phase_2_trace_secteur OWNER to redadeg;
|
||||
|
||||
-- une vue en 4326 pour export
|
||||
DROP VIEW IF EXISTS phase_2_trace_secteur_4326 ;
|
||||
CREATE VIEW phase_2_trace_secteur_4326 AS
|
||||
SELECT
|
||||
secteur_id, nom_fr, nom_br,
|
||||
longueur, longueur_km,
|
||||
ST_Transform(the_geom,4326)::geometry(MultiLineString, 4326) AS the_geom
|
||||
FROM phase_2_trace_secteur ;
|
||||
ALTER TABLE phase_2_trace_secteur_4326 OWNER to redadeg;
|
||||
|
||||
|
||||
-- ça sert à quoi ça ?
|
||||
DROP TABLE IF EXISTS phase_2_trace_trous CASCADE ;
|
||||
CREATE TABLE phase_2_trace_trous
|
||||
(
|
||||
id serial,
|
||||
secteur_id int,
|
||||
the_geom geometry,
|
||||
CONSTRAINT phase_2_trace_trous_pkid PRIMARY KEY (id),
|
||||
CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'POINT'::text),
|
||||
CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 2154)
|
||||
);
|
||||
ALTER TABLE phase_2_trace_trous OWNER to redadeg;
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
-- la table qui va contenir des tronçons de x m
|
||||
DROP TABLE IF EXISTS phase_2_trace_troncons CASCADE ;
|
||||
CREATE TABLE phase_2_trace_troncons
|
||||
(
|
||||
uid bigint,
|
||||
secteur_id int,
|
||||
ordre bigint,
|
||||
km bigint,
|
||||
km_reel bigint,
|
||||
longueur integer,
|
||||
-- info OSM
|
||||
osm_id bigint,
|
||||
highway text,
|
||||
type text,
|
||||
oneway text,
|
||||
ref text,
|
||||
name_fr text,
|
||||
name_br text,
|
||||
the_geom geometry,
|
||||
CONSTRAINT phase_2_trace_troncons_pkey PRIMARY KEY (uid),
|
||||
CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'LINESTRING'::text),
|
||||
CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 2154)
|
||||
);
|
||||
ALTER TABLE phase_2_trace_troncons OWNER to redadeg;
|
||||
|
||||
|
||||
DROP VIEW IF EXISTS phase_2_tdb ;
|
||||
CREATE VIEW phase_2_tdb AS
|
||||
WITH total AS
|
||||
(
|
||||
SELECT
|
||||
0 AS secteur_id, 'Total' AS nom_fr, 'Hollad' AS nom_br,
|
||||
SUM(longueur_km) AS longueur_km
|
||||
FROM public.phase_2_trace_secteur
|
||||
GROUP BY 1
|
||||
)
|
||||
SELECT
|
||||
a.secteur_id, a.nom_fr, a.nom_br,
|
||||
a.longueur_km,
|
||||
-- b.km_reels AS longueur_km_attendu, << vérifier si ça sert
|
||||
-- -(b.km_reels - a.longueur_km) AS difference, << vérifier si ça sert
|
||||
TRUNC(a.longueur_km / (SELECT longueur_km FROM total) * 2020, 0) AS nb_km_redadeg
|
||||
--TRUNC((a.longueur_km / (SELECT longueur_km FROM total) * 2020) / b.km_reels, 3) AS longueur_km_redadeg
|
||||
FROM phase_2_trace_secteur a JOIN secteur b ON a.secteur_id = b.id
|
||||
UNION
|
||||
SELECT
|
||||
0 AS secteur_id, 'Total' AS nom_fr, 'Hollad' AS nom_br,
|
||||
SUM(longueur_km) AS longueur_km,
|
||||
0
|
||||
-- 0,0,0
|
||||
FROM public.phase_2_trace_secteur
|
||||
GROUP BY 1
|
||||
ORDER BY secteur_id ASC ;
|
||||
ALTER TABLE phase_2_tdb OWNER TO redadeg;
|
||||
|
||||
|
||||
|
||||
|
||||
/*
|
||||
==========================================================================
|
||||
|
||||
phase 3 : calcul des PK auto
|
||||
|
||||
==========================================================================
|
||||
*/
|
||||
|
||||
DROP TABLE IF EXISTS phase_3_trace_troncons CASCADE ;
|
||||
CREATE TABLE phase_3_trace_troncons
|
||||
(
|
||||
troncon_id bigint,
|
||||
secteur_id int,
|
||||
the_geom geometry,
|
||||
CONSTRAINT phase_3_trace_troncons_pkey PRIMARY KEY (troncon_id),
|
||||
--CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'LINESTRING'::text),
|
||||
--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 phase_3_trace_troncons OWNER TO redadeg;
|
||||
|
||||
-- la même couche en 4326
|
||||
DROP VIEW IF EXISTS phase_3_trace_troncons_4326 ;
|
||||
CREATE VIEW phase_3_trace_troncons_4326 AS
|
||||
SELECT
|
||||
troncon_id,
|
||||
secteur_id,
|
||||
ST_Transform(the_geom,4326) AS the_geom
|
||||
FROM phase_3_trace_troncons ;
|
||||
ALTER TABLE phase_3_trace_troncons_4326 OWNER TO redadeg;
|
||||
|
||||
|
||||
|
||||
DROP TABLE IF EXISTS phase_3_trace_secteurs CASCADE ;
|
||||
CREATE TABLE phase_3_trace_secteurs
|
||||
(
|
||||
secteur_id int,
|
||||
nom_fr text,
|
||||
nom_br text,
|
||||
km_reels numeric(8,2),
|
||||
the_geom geometry,
|
||||
CONSTRAINT phase_3_trace_secteurs_pkey PRIMARY KEY (secteur_id),
|
||||
--CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'LINESTRING'::text OR geometrytype(the_geom) = 'MULTILINESTRING'::text),
|
||||
--CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'LINESTRING'::text),
|
||||
CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 2154)
|
||||
);
|
||||
ALTER TABLE phase_3_trace_secteurs OWNER TO redadeg;
|
||||
|
||||
-- la même couche en 4326
|
||||
DROP VIEW IF EXISTS phase_3_trace_secteurs_4326 ;
|
||||
CREATE VIEW phase_3_trace_secteurs_4326 AS
|
||||
SELECT
|
||||
secteur_id, nom_fr, nom_br,
|
||||
km_reels,
|
||||
ST_Transform(the_geom,4326) AS the_geom
|
||||
FROM phase_3_trace_secteurs ;
|
||||
ALTER TABLE phase_3_trace_secteurs_4326 OWNER TO redadeg;
|
||||
|
||||
|
||||
|
||||
-- la couche des PK calculés automatiquement
|
||||
DROP TABLE IF EXISTS phase_3_pk_auto CASCADE ;
|
||||
CREATE TABLE phase_3_pk_auto
|
||||
(
|
||||
pk_id integer,
|
||||
pk_x numeric(8,1),
|
||||
pk_y numeric(8,1),
|
||||
pk_long numeric(10,8),
|
||||
pk_lat numeric(10,8),
|
||||
length_real numeric(6,2),
|
||||
length_theorical integer,
|
||||
secteur_id integer,
|
||||
municipality_admincode text,
|
||||
municipality_postcode text,
|
||||
municipality_name_fr text,
|
||||
municipality_name_br text,
|
||||
way_osm_id bigint,
|
||||
way_highway text,
|
||||
way_type text,
|
||||
way_oneway text,
|
||||
way_ref text,
|
||||
way_name_fr text,
|
||||
way_name_br text,
|
||||
the_geom geometry,
|
||||
CONSTRAINT phase_3_pk_auto_pkey PRIMARY KEY (pk_id),
|
||||
CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'POINT'::text),
|
||||
CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 2154)
|
||||
) ;
|
||||
ALTER TABLE phase_3_pk_auto OWNER TO redadeg;
|
||||
|
||||
|
||||
-- la même couche en 4326
|
||||
DROP VIEW IF EXISTS phase_3_pk_auto_4326 ;
|
||||
CREATE VIEW phase_3_pk_auto_4326 AS
|
||||
SELECT
|
||||
pk_id,
|
||||
pk_x, pk_y, pk_long, pk_lat,
|
||||
length_real, length_theorical,
|
||||
secteur_id,
|
||||
municipality_admincode, municipality_postcode,
|
||||
municipality_name_fr, municipality_name_br,
|
||||
way_osm_id, way_highway, way_type, way_oneway, way_ref,
|
||||
way_name_fr, way_name_br,
|
||||
ST_Transform(the_geom,4326)::geometry(Point, 4326) AS the_geom
|
||||
FROM phase_3_pk_auto ;
|
||||
ALTER TABLE phase_3_pk_auto_4326 OWNER TO redadeg;
|
||||
|
||||
|
||||
-- couche de lignes simples directes de PK à PK
|
||||
DROP TABLE IF EXISTS phase_3_pk_sens_verif ;
|
||||
CREATE TABLE phase_3_pk_sens_verif
|
||||
(
|
||||
secteur_id integer,
|
||||
the_geom geometry,
|
||||
CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'LINESTRING'::text),
|
||||
CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 2154)
|
||||
) ;
|
||||
ALTER TABLE phase_3_pk_sens_verif OWNER TO redadeg;
|
||||
|
||||
|
||||
-- la même couche en 4326
|
||||
DROP VIEW IF EXISTS phase_3_pk_sens_verif_4326 ;
|
||||
CREATE VIEW phase_3_pk_sens_verif_4326 AS
|
||||
SELECT
|
||||
secteur_id,
|
||||
ST_Transform(the_geom,4326)::geometry(LineString, 4326) AS the_geom
|
||||
FROM phase_3_pk_sens_verif ;
|
||||
ALTER TABLE phase_3_pk_sens_verif_4326 OWNER TO redadeg;
|
||||
|
||||
|
||||
|
||||
|
||||
/*
|
||||
==========================================================================
|
||||
|
||||
phase 4 : création de la couche des PK à charger dans umap pour la phase 5
|
||||
|
||||
==========================================================================
|
||||
*/
|
||||
|
||||
|
||||
DROP VIEW IF EXISTS phase_4_pk_auto_4326 CASCADE ;
|
||||
CREATE VIEW phase_4_pk_auto_4326 AS
|
||||
SELECT
|
||||
pk_id,
|
||||
secteur_id,
|
||||
ST_Transform(the_geom,4326)::geometry(Point, 4326) AS the_geom
|
||||
FROM phase_3_pk_auto ;
|
||||
ALTER TABLE phase_4_pk_auto_4326 OWNER TO redadeg;
|
||||
|
||||
|
||||
|
||||
|
||||
/*
|
||||
==========================================================================
|
||||
|
||||
phase 5 : gestion manuelle
|
||||
|
||||
==========================================================================
|
||||
*/
|
||||
|
||||
-- la table des PK avant modifications manuelles = PK de référence = phase_3_pk_auto
|
||||
DROP TABLE IF EXISTS phase_5_pk_ref CASCADE ;
|
||||
CREATE TABLE phase_5_pk_ref
|
||||
(
|
||||
pk_id integer,
|
||||
pk_x numeric(8,1),
|
||||
pk_y numeric(8,1),
|
||||
pk_long numeric(10,8),
|
||||
pk_lat numeric(10,8),
|
||||
length_real numeric(6,2),
|
||||
length_theorical integer,
|
||||
secteur_id integer,
|
||||
municipality_admincode text,
|
||||
municipality_postcode text,
|
||||
municipality_name_fr text,
|
||||
municipality_name_br text,
|
||||
way_osm_id bigint,
|
||||
way_highway text,
|
||||
way_type text,
|
||||
way_oneway text,
|
||||
way_ref text,
|
||||
way_name_fr text,
|
||||
way_name_br text,
|
||||
the_geom geometry,
|
||||
CONSTRAINT phase_5_pk_ref_pkey PRIMARY KEY (pk_id),
|
||||
CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'POINT'::text),
|
||||
CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 2154)
|
||||
) ;
|
||||
ALTER TABLE phase_5_pk_ref OWNER TO redadeg;
|
||||
|
||||
-- on charge cette table avec les données finales de la phase 3
|
||||
TRUNCATE TABLE phase_5_pk_ref ;
|
||||
INSERT INTO phase_5_pk_ref SELECT * FROM phase_3_pk_auto ;
|
||||
|
||||
|
||||
-- on définit manuellement la couche avec un type mixte parce qu'on a des lignes dans la couche de points…
|
||||
DROP TABLE IF EXISTS phase_5_pk_umap_4326 CASCADE ;
|
||||
CREATE TABLE phase_5_pk_umap_4326
|
||||
(
|
||||
ogc_fid integer,
|
||||
pk_id integer,
|
||||
secteur_id integer,
|
||||
the_geom geometry,
|
||||
--CONSTRAINT phase_5_pk_umap_pkey PRIMARY KEY (ogc_fid),
|
||||
CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 4326)
|
||||
);
|
||||
ALTER TABLE phase_5_pk_umap_4326 OWNER TO redadeg;
|
||||
|
||||
-- la table en 2154 pour travailler
|
||||
DROP TABLE IF EXISTS phase_5_pk_umap CASCADE ;
|
||||
CREATE TABLE phase_5_pk_umap
|
||||
(
|
||||
pk_id integer,
|
||||
secteur_id integer,
|
||||
the_geom geometry,
|
||||
CONSTRAINT phase_5_pk_umap_pkey PRIMARY KEY (pk_id),
|
||||
CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'POINT'::text),
|
||||
CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 2154)
|
||||
);
|
||||
ALTER TABLE phase_5_pk_umap OWNER TO redadeg;
|
||||
|
||||
|
||||
-- la table finale
|
||||
DROP TABLE IF EXISTS phase_5_pk CASCADE ;
|
||||
CREATE TABLE phase_5_pk
|
||||
(
|
||||
pk_id integer,
|
||||
pk_x numeric(8,1),
|
||||
pk_y numeric(8,1),
|
||||
pk_long numeric(10,8),
|
||||
pk_lat numeric(10,8),
|
||||
length_real numeric(6,2),
|
||||
length_theorical integer,
|
||||
secteur_id integer,
|
||||
municipality_admincode text,
|
||||
municipality_postcode text,
|
||||
municipality_name_fr text,
|
||||
municipality_name_br text,
|
||||
way_osm_id bigint,
|
||||
way_highway text,
|
||||
way_type text,
|
||||
way_oneway text,
|
||||
way_ref text,
|
||||
way_name_fr text,
|
||||
way_name_br text,
|
||||
the_geom geometry,
|
||||
CONSTRAINT phase_5_pk_pkey PRIMARY KEY (pk_id),
|
||||
CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'POINT'::text),
|
||||
CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 2154)
|
||||
) ;
|
||||
ALTER TABLE phase_5_pk OWNER TO redadeg;
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
|
@ -1,41 +0,0 @@
|
|||
/*
|
||||
|
||||
SELECT 'DROP TABLE ' || TABLE_NAME || ' CASCADE ;' AS SQL
|
||||
FROM information_schema.tables
|
||||
WHERE
|
||||
table_schema = 'public'
|
||||
AND table_type = 'BASE TABLE'
|
||||
AND TABLE_NAME NOT IN ('geography_columns','geometry_columns','raster_columns','raster_overviews','spatial_ref_sys')
|
||||
ORDER BY TABLE_NAME
|
||||
|
||||
*/
|
||||
|
||||
|
||||
DROP TABLE osm_communes CASCADE ;
|
||||
DROP TABLE osm_roads CASCADE ;
|
||||
DROP TABLE osm_roads_pgr CASCADE ;
|
||||
DROP TABLE osm_roads_pgr_patch CASCADE ;
|
||||
DROP TABLE osm_roads_pgr_patch_mask CASCADE ;
|
||||
DROP TABLE phase_1_pk_vip CASCADE ;
|
||||
DROP TABLE phase_1_pk_vip_3857 CASCADE ;
|
||||
DROP TABLE phase_1_trace CASCADE ;
|
||||
DROP TABLE phase_1_trace_3857 CASCADE ;
|
||||
DROP TABLE phase_1_trace_4326 CASCADE ;
|
||||
DROP TABLE phase_1_trace_troncons CASCADE ;
|
||||
DROP TABLE phase_2_pk_secteur CASCADE ;
|
||||
DROP TABLE phase_2_pk_secteur_3857 CASCADE ;
|
||||
DROP TABLE phase_2_point_nettoyage CASCADE ;
|
||||
DROP TABLE phase_2_point_nettoyage_3857 CASCADE ;
|
||||
DROP TABLE phase_2_trace_pgr CASCADE ;
|
||||
DROP TABLE phase_2_trace_secteur CASCADE ;
|
||||
DROP TABLE phase_2_trace_troncons CASCADE ;
|
||||
DROP TABLE phase_2_trace_trous CASCADE ;
|
||||
DROP TABLE phase_3_pk_auto CASCADE ;
|
||||
DROP TABLE phase_3_pk_sens_verif CASCADE ;
|
||||
DROP TABLE phase_3_trace_secteurs CASCADE ;
|
||||
DROP TABLE phase_3_trace_troncons CASCADE ;
|
||||
DROP TABLE phase_5_pk CASCADE ;
|
||||
DROP TABLE phase_5_pk_ref CASCADE ;
|
||||
DROP TABLE phase_5_pk_umap CASCADE ;
|
||||
DROP TABLE phase_5_pk_umap_4326 CASCADE ;
|
||||
DROP TABLE secteur CASCADE ;
|
|
@ -1,722 +0,0 @@
|
|||
#! <?xml version="1.0" encoding="UTF-8" ?>
|
||||
#! <WORKSPACE
|
||||
# Command-line to run this workspace:
|
||||
# /Library/FME/2021.0/fme /Volumes/ker/mael/projets/osm_bzh/github/ar_redadeg/scripts/export_prefecture_liste_voies.fmw
|
||||
# --DestDataset_CSV2 "/Volumes/ker/mael/projets/osm_bzh/github/ar_redadeg/data/2021"
|
||||
#
|
||||
#! ARCGIS_COMPATIBILITY="ARCGIS_AUTO"
|
||||
#! ATTR_TYPE_ENCODING="SDF"
|
||||
#! BEGIN_PYTHON=""
|
||||
#! BEGIN_TCL=""
|
||||
#! CATEGORY=""
|
||||
#! DESCRIPTION=""
|
||||
#! DESTINATION="NONE"
|
||||
#! DESTINATION_ROUTING_FILE=""
|
||||
#! DOC_EXTENTS="1886.02 121.498"
|
||||
#! DOC_TOP_LEFT="111.001 -544.502"
|
||||
#! END_PYTHON=""
|
||||
#! END_TCL=""
|
||||
#! EXPLICIT_BOOKMARK_ORDER="false"
|
||||
#! FME_BUILD_NUM="21306"
|
||||
#! FME_DOCUMENT_GUID="c22220ae-dc47-47c8-9b45-682e7e2d9c51"
|
||||
#! FME_DOCUMENT_PRIORGUID="c156843b-406b-4b08-ae82-1bd2890bdbce"
|
||||
#! FME_GEOMETRY_HANDLING="Enhanced"
|
||||
#! FME_IMPLICIT_CSMAP_REPROJECTION_MODE="Auto"
|
||||
#! FME_NAMES_ENCODING="UTF-8"
|
||||
#! FME_REPROJECTION_ENGINE="FME"
|
||||
#! FME_SERVER_SERVICES=""
|
||||
#! FME_STROKE_MAX_DEVIATION="0"
|
||||
#! HISTORY=""
|
||||
#! IGNORE_READER_FAILURE="No"
|
||||
#! LAST_SAVE_BUILD="FME(R) 2021.0.0.1 (20210315 - Build 21306 - macosx)"
|
||||
#! LAST_SAVE_DATE="2021-05-04T22:34:08"
|
||||
#! LOG_FILE=""
|
||||
#! LOG_MAX_RECORDED_FEATURES="200"
|
||||
#! MARKDOWN_DESCRIPTION=""
|
||||
#! MARKDOWN_USAGE=""
|
||||
#! MAX_LOG_FEATURES="200"
|
||||
#! MULTI_WRITER_DATASET_ORDER="BY_ID"
|
||||
#! PASSWORD=""
|
||||
#! PYTHON_COMPATIBILITY="38"
|
||||
#! REDIRECT_TERMINATORS="NONE"
|
||||
#! SAVE_ON_PROMPT_AND_RUN="Yes"
|
||||
#! SHOW_ANNOTATIONS="true"
|
||||
#! SHOW_INFO_NODES="true"
|
||||
#! SOURCE="NONE"
|
||||
#! SOURCE_ROUTING_FILE=""
|
||||
#! TERMINATE_REJECTED="YES"
|
||||
#! TITLE=""
|
||||
#! USAGE=""
|
||||
#! USE_MARKDOWN=""
|
||||
#! VIEW_POSITION="-342.003 0"
|
||||
#! WARN_INVALID_XFORM_PARAM="Yes"
|
||||
#! WORKSPACE_VERSION="1"
|
||||
#! ZOOM_SCALE="100"
|
||||
#! >
|
||||
#! <DATASETS>
|
||||
#! <DATASET
|
||||
#! IS_SOURCE="false"
|
||||
#! ROLE="WRITER"
|
||||
#! FORMAT="CSV2"
|
||||
#! DATASET="$(DestDataset_CSV2)"
|
||||
#! KEYWORD="CSV2_1"
|
||||
#! MULTI_GEOM_ALLOWED="true"
|
||||
#! ATTR_MAX_LENGTH="255"
|
||||
#! ATTR_CASE="ANY"
|
||||
#! ALLOWED_FEAT_TYPES=""
|
||||
#! WRITE_DEFS="true"
|
||||
#! DEFLINE_TEMPLATE="csv_existing_file_handling Yes csv_write_field_names firstrow"
|
||||
#! DEFLINE_ATTRS="true"
|
||||
#! EXPOSABLE_ATTRS="csv_type string fme_basename string fme_color string fme_dataset string fme_feature_type string fme_fill_color string fme_geometry string fme_primary_axis string fme_rotation string fme_secondary_axis string fme_start_angle string fme_sweep_angle string fme_text_size string fme_text_string string fme_type string"
|
||||
#! DEFLINE_PARMS=""GUI OPTIONAL NAMEDGROUP csv_dataset_group csv_existing_file_handling Dataset" "" "GUI CHOICE csv_existing_file_handling Yes%No Overwrite Existing File" Yes "GUI OPTIONAL NAMEDGROUP csv_fields_group csv_write_field_names Fields" "" "GUI LOOKUP_CHOICE csv_write_field_names If<space>Writing<space>First<space>Row,firstrow%Yes,yes%No,no Write Field Names Row" firstrow "
|
||||
#! ATTR_INDEX_TYPES=""
|
||||
#! ATTR_NAME_INVALID_CHARS=""*{}$"
|
||||
#! SUPPORTS_FEATURE_TYPE_FANOUT="true"
|
||||
#! ENABLED="true"
|
||||
#! DYNAMIC_FEATURE_TYPES_LIST_ON_MERGE="true"
|
||||
#! DATASET_TYPE="FILEDIR"
|
||||
#! FTTR_TYPE=""
|
||||
#! GENERATE_FME_BUILD_NUM="21306"
|
||||
#! COORDSYS=""
|
||||
#! FANOUT_EXPRESSION=""
|
||||
#! FANOUT_GROUP="NO"
|
||||
#! >
|
||||
#! <METAFILE_PARAMETER
|
||||
#! NAME="ADVANCED_PARMS"
|
||||
#! VALUE="CSV2_OUT_QUALIFY_FIELD_NAMES CSV2_OUT_QUALIFY_FIELD_VALUES CSV2_OUT_FIELD_QUALIFIER_CHARACTER CSV2_OUT_FIELD_QUALIFIER_ESCAPE_CHARACTER CSV2_OUT_ROW_TERMINATION CSV2_OUT_WRITE_SCHEMA_FILE CSV2_OUT_EXISTING_SCHEMA_FILE_HANDLING"
|
||||
#! />
|
||||
#! <METAFILE_PARAMETER
|
||||
#! NAME="ATTRIBUTE_READING"
|
||||
#! VALUE="DEFLINE"
|
||||
#! />
|
||||
#! <METAFILE_PARAMETER
|
||||
#! NAME="DATASET_NAME"
|
||||
#! VALUE="csv file"
|
||||
#! />
|
||||
#! <METAFILE_PARAMETER
|
||||
#! NAME="DEFAULT_ATTR_TYPE"
|
||||
#! VALUE="string"
|
||||
#! />
|
||||
#! <METAFILE_PARAMETER
|
||||
#! NAME="FEATURE_TYPE_DEFAULT_NAME"
|
||||
#! VALUE="File1"
|
||||
#! />
|
||||
#! <METAFILE_PARAMETER
|
||||
#! NAME="FEATURE_TYPE_NAME"
|
||||
#! VALUE="CSV File"
|
||||
#! />
|
||||
#! <METAFILE_PARAMETER
|
||||
#! NAME="READER_DATASET_HINT"
|
||||
#! VALUE="Select the CSV file(s)"
|
||||
#! />
|
||||
#! <METAFILE_PARAMETER
|
||||
#! NAME="WRITER_DATASET_HINT"
|
||||
#! VALUE="Specify a folder for the CSV file"
|
||||
#! />
|
||||
#! </DATASET>
|
||||
#! </DATASETS>
|
||||
#! <DATA_TYPES>
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_buffer"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_binarybuffer"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_xml"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_json"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_varchar(width)"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_varbinary(width)"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_char(width)"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_binary(width)"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_datetime"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_time"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_date"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_real64"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="real64"
|
||||
#! FME_TYPE="fme_real64"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="x_coordinate"
|
||||
#! FME_TYPE="fme_real64"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="y_coordinate"
|
||||
#! FME_TYPE="fme_real64"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="z_coordinate"
|
||||
#! FME_TYPE="fme_real64"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_real32"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="real32"
|
||||
#! FME_TYPE="fme_real32"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_int64"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="int64"
|
||||
#! FME_TYPE="fme_int64"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_int32"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="int32"
|
||||
#! FME_TYPE="fme_int32"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_int16"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="int16"
|
||||
#! FME_TYPE="fme_int16"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_int8"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="int8"
|
||||
#! FME_TYPE="fme_int8"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_uint64"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="uint64"
|
||||
#! FME_TYPE="fme_uint64"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_uint32"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="uint32"
|
||||
#! FME_TYPE="fme_uint32"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_uint16"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="uint16"
|
||||
#! FME_TYPE="fme_uint16"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_uint8"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="uint8"
|
||||
#! FME_TYPE="fme_uint8"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_boolean"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="boolean"
|
||||
#! FME_TYPE="fme_boolean"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <DATA_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="string"
|
||||
#! FME_TYPE="fme_decimal(width,decimal)"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! </DATA_TYPES>
|
||||
#! <GEOM_TYPES>
|
||||
#! <GEOM_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="csv_feature_table"
|
||||
#! FME_TYPE="fme_feature_table"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <GEOM_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="csv_none"
|
||||
#! FME_TYPE="fme_no_geom"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <GEOM_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="csv_point"
|
||||
#! FME_TYPE="fme_point"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <GEOM_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="csv_none"
|
||||
#! FME_TYPE="fme_line"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <GEOM_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="csv_none"
|
||||
#! FME_TYPE="fme_area"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <GEOM_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="csv_none"
|
||||
#! FME_TYPE="fme_text"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <GEOM_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="csv_none"
|
||||
#! FME_TYPE="fme_ellipse"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <GEOM_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="csv_none"
|
||||
#! FME_TYPE="fme_arc"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <GEOM_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="csv_none"
|
||||
#! FME_TYPE="fme_rectangle"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <GEOM_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="csv_none"
|
||||
#! FME_TYPE="fme_rounded_rectangle"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <GEOM_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="fme_no_map"
|
||||
#! FME_TYPE="fme_no_geom"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <GEOM_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="fme_no_map"
|
||||
#! FME_TYPE="fme_no_map"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <GEOM_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="csv_none"
|
||||
#! FME_TYPE="fme_collection"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <GEOM_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="csv_none"
|
||||
#! FME_TYPE="fme_raster"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <GEOM_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="csv_none"
|
||||
#! FME_TYPE="fme_surface"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <GEOM_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="csv_none"
|
||||
#! FME_TYPE="fme_solid"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <GEOM_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="csv_none"
|
||||
#! FME_TYPE="fme_point_cloud"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! <GEOM_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! FORMAT_TYPE="csv_none"
|
||||
#! FME_TYPE="fme_voxel_grid"
|
||||
#! FORMAT="CSV2"
|
||||
#! />
|
||||
#! </GEOM_TYPES>
|
||||
#! <FEATURE_TYPES>
|
||||
#! <FEATURE_TYPE
|
||||
#! IS_SOURCE="false"
|
||||
#! NODE_NAME="ar_redadeg_prefecture"
|
||||
#! FEATURE_TYPE_NAME=""
|
||||
#! FEATURE_TYPE_NAME_QUALIFIER=""
|
||||
#! IS_EDITABLE="false"
|
||||
#! IDENTIFIER="4"
|
||||
#! FEAT_GEOMTYPE="<NO_GEOMETRY>"
|
||||
#! POSITION="1411.0084300843005 -473.50207002070022"
|
||||
#! BOUNDING_RECT="1411.0084300843005 -473.50207002070022 586.01669325772946 71"
|
||||
#! ORDER="500000000000000"
|
||||
#! COLLAPSED="false"
|
||||
#! KEYWORD="CSV2_1"
|
||||
#! PARMS_EDITED="false"
|
||||
#! ENABLED="true"
|
||||
#! SCHEMA_ATTRIBUTE_SOURCE="0"
|
||||
#! >
|
||||
#! <FEAT_ATTRIBUTE ATTR_NAME="dpt" ATTR_TYPE="string" ATTR_HAS_PORT="true" ATTR_VALUE=""/>
|
||||
#! <FEAT_ATTRIBUTE ATTR_NAME="insee" ATTR_TYPE="string" ATTR_HAS_PORT="true" ATTR_VALUE=""/>
|
||||
#! <FEAT_ATTRIBUTE ATTR_NAME="nom" ATTR_TYPE="string" ATTR_HAS_PORT="true" ATTR_VALUE=""/>
|
||||
#! <FEAT_ATTRIBUTE ATTR_NAME="pk_id" ATTR_TYPE="string" ATTR_HAS_PORT="true" ATTR_VALUE=""/>
|
||||
#! <FEAT_ATTRIBUTE ATTR_NAME="voie_ref" ATTR_TYPE="string" ATTR_HAS_PORT="true" ATTR_VALUE=""/>
|
||||
#! <FEAT_ATTRIBUTE ATTR_NAME="voie_nom" ATTR_TYPE="string" ATTR_HAS_PORT="true" ATTR_VALUE=""/>
|
||||
#! <DEFLINE_PARM PARM_NAME="csv_dataset_group" PARM_VALUE=""/>
|
||||
#! <DEFLINE_PARM PARM_NAME="csv_existing_file_handling" PARM_VALUE="Yes"/>
|
||||
#! <DEFLINE_PARM PARM_NAME="csv_fields_group" PARM_VALUE=""/>
|
||||
#! <DEFLINE_PARM PARM_NAME="csv_write_field_names" PARM_VALUE="firstrow"/>
|
||||
#! </FEATURE_TYPE>
|
||||
#! </FEATURE_TYPES>
|
||||
#! <FMESERVER>
|
||||
#! <WRITER_DATASETS>
|
||||
#! <DATASET
|
||||
#! NAME="CSV2_1"
|
||||
#! OVERRIDE="-CSV2_1_DATASET"
|
||||
#! DATASET="CSV2_1/2021"
|
||||
#! />
|
||||
#! </WRITER_DATASETS>
|
||||
#! <CONNECTIONS>
|
||||
#! <CONNECTION
|
||||
#! NAME="bed110@redadeg_2021@redadeg"
|
||||
#! TYPE="DATABASE"
|
||||
#! FAMILY="PostgreSQL"
|
||||
#! USAGE="INTERNAL"
|
||||
#! />
|
||||
#! </CONNECTIONS>
|
||||
#! </FMESERVER>
|
||||
#! <GLOBAL_PARAMETERS>
|
||||
#! <GLOBAL_PARAMETER
|
||||
#! GUI_LINE="GUI DIRNAME DestDataset_CSV2 Destination CSV (Comma Separated Value) Folder:"
|
||||
#! DEFAULT_VALUE="/Volumes/ker/mael/projets/osm_bzh/github/ar_redadeg/data/2021"
|
||||
#! IS_STAND_ALONE="false"
|
||||
#! />
|
||||
#! </GLOBAL_PARAMETERS>
|
||||
#! <USER_PARAMETERS
|
||||
#! FORM="eyJwYXJhbWV0ZXJzIjpbeyJhY2Nlc3NNb2RlIjoid3JpdGUiLCJkZWZhdWx0VmFsdWUiOiIvVm9sdW1lcy9rZXIvbWFlbC9wcm9qZXRzL29zbV9iemgvZ2l0aHViL2FyX3JlZGFkZWcvZGF0YS8yMDIxIiwiaXRlbXNUb1NlbGVjdCI6ImZvbGRlcnMiLCJuYW1lIjoiRGVzdERhdGFzZXRfQ1NWMiIsInByb21wdCI6IkRlc3RpbmF0aW9uIENTViAoQ29tbWEgU2VwYXJhdGVkIFZhbHVlKSBGb2xkZXI6IiwicmVxdWlyZWQiOnRydWUsInNlbGVjdE11bHRpcGxlIjpmYWxzZSwidHlwZSI6ImZpbGUiLCJ2YWxpZGF0ZUV4aXN0ZW5jZSI6ZmFsc2UsInZhbHVlVHlwZSI6InN0cmluZyJ9XX0="
|
||||
#! >
|
||||
#! <PARAMETER_INFO>
|
||||
#! <INFO NAME="DestDataset_CSV2" IS_STAND_ALONE="false" />
|
||||
#! </PARAMETER_INFO>
|
||||
#! </USER_PARAMETERS>
|
||||
#! <COMMENTS>
|
||||
#! </COMMENTS>
|
||||
#! <CONSTANTS>
|
||||
#! </CONSTANTS>
|
||||
#! <BOOKMARKS>
|
||||
#! </BOOKMARKS>
|
||||
#! <TRANSFORMERS>
|
||||
#! <TRANSFORMER
|
||||
#! IDENTIFIER="9"
|
||||
#! TYPE="SQLCreator"
|
||||
#! VERSION="3"
|
||||
#! POSITION="111.00111001110014 -423.00423004230038"
|
||||
#! BOUNDING_RECT="111.00111001110014 -423.00423004230038 430 71"
|
||||
#! ORDER="500000000000148"
|
||||
#! PARMS_EDITED="true"
|
||||
#! ENABLED="true"
|
||||
#! LAST_PARM_EDIT="21306"
|
||||
#! >
|
||||
#! <OUTPUT_FEAT NAME="RESULT"/>
|
||||
#! <XFORM_ATTR ATTR_NAME="dpt" IS_USER_CREATED="false" FEAT_INDEX="0" />
|
||||
#! <XFORM_ATTR ATTR_NAME="insee" IS_USER_CREATED="false" FEAT_INDEX="0" />
|
||||
#! <XFORM_ATTR ATTR_NAME="nom" IS_USER_CREATED="false" FEAT_INDEX="0" />
|
||||
#! <XFORM_ATTR ATTR_NAME="pk_id" IS_USER_CREATED="false" FEAT_INDEX="0" />
|
||||
#! <XFORM_ATTR ATTR_NAME="voie_ref" IS_USER_CREATED="false" FEAT_INDEX="0" />
|
||||
#! <XFORM_ATTR ATTR_NAME="voie_nom" IS_USER_CREATED="false" FEAT_INDEX="0" />
|
||||
#! <OUTPUT_FEAT NAME="<REJECTED>"/>
|
||||
#! <FEAT_COLLAPSED COLLAPSED="1"/>
|
||||
#! <XFORM_ATTR ATTR_NAME="_reader_error" IS_USER_CREATED="false" FEAT_INDEX="1" />
|
||||
#! <XFORM_ATTR ATTR_NAME="dpt" IS_USER_CREATED="false" FEAT_INDEX="1" />
|
||||
#! <XFORM_ATTR ATTR_NAME="insee" IS_USER_CREATED="false" FEAT_INDEX="1" />
|
||||
#! <XFORM_ATTR ATTR_NAME="nom" IS_USER_CREATED="false" FEAT_INDEX="1" />
|
||||
#! <XFORM_ATTR ATTR_NAME="pk_id" IS_USER_CREATED="false" FEAT_INDEX="1" />
|
||||
#! <XFORM_ATTR ATTR_NAME="voie_ref" IS_USER_CREATED="false" FEAT_INDEX="1" />
|
||||
#! <XFORM_ATTR ATTR_NAME="voie_nom" IS_USER_CREATED="false" FEAT_INDEX="1" />
|
||||
#! <XFORM_PARM PARM_NAME="COORDSYS" PARM_VALUE=""/>
|
||||
#! <XFORM_PARM PARM_NAME="DATASET" PARM_VALUE="bed110<at>redadeg_2021<at>redadeg"/>
|
||||
#! <XFORM_PARM PARM_NAME="DB_GROUP" PARM_VALUE=""/>
|
||||
#! <XFORM_PARM PARM_NAME="DYNGROUP_0" PARM_VALUE=""/>
|
||||
#! <XFORM_PARM PARM_NAME="EXPOSED_ATTRIBUTE_LIST" PARM_VALUE="dpt insee nom pk_id voie_ref voie_nom"/>
|
||||
#! <XFORM_PARM PARM_NAME="FEATURETYPES" PARM_VALUE=""/>
|
||||
#! <XFORM_PARM PARM_NAME="FORMAT" PARM_VALUE="POSTGRES"/>
|
||||
#! <XFORM_PARM PARM_NAME="FORMAT_PARAMS" PARM_VALUE="POSTGRES_SCHEMAS_FOR_TABLE_LISTING,"IGNORE TEXT",POSTGRES<space>Schemas<space>for<space>Tables:,POSTGRES_NAMED_CONNECTION,"IGNORE TEXT",POSTGRES<space>Connection:"/>
|
||||
#! <XFORM_PARM PARM_NAME="PARAMETERS_GROUP" PARM_VALUE=""/>
|
||||
#! <XFORM_PARM PARM_NAME="POSTGRES_NAMED_CONNECTION" PARM_VALUE="bed110<at>redadeg_2021<at>redadeg"/>
|
||||
#! <XFORM_PARM PARM_NAME="POSTGRES_SCHEMAS_FOR_TABLE_LISTING" PARM_VALUE=""/>
|
||||
#! <XFORM_PARM PARM_NAME="SQL_STATEMENT" PARM_VALUE="SELECT<lf><space><space>left<openparen>com.insee<comma>2<closeparen><space>as<space>dpt<comma><lf><space><space>com.insee<comma><space>com.nom<comma><lf><space><space>pk.pk_id<comma><space>pk.way_ref<space>as<space>voie_ref<comma><lf><space><space>CASE<lf><space><space><space><space>WHEN<space>way_name_fr<space>IS<space>NULL<space>THEN<space><apos><openparen>voie<space>non<space>d<u00e9>nomm<u00e9>e<closeparen><apos><lf><tab>ELSE<space>way_name_fr<lf><space><space>END<space>as<space>voie_nom<lf>FROM<space>phase_3_pk_auto<space>pk<comma><space>osm_communes<space>com<lf>WHERE<space>ST_Intersects<openparen>pk.the_geom<comma>com.the_geom<closeparen><lf>ORDER<space>BY<space>pk_id"/>
|
||||
#! <XFORM_PARM PARM_NAME="TRANSFORMER_GROUP" PARM_VALUE=""/>
|
||||
#! <XFORM_PARM PARM_NAME="XFORMER_NAME" PARM_VALUE="SQLCreator"/>
|
||||
#! </TRANSFORMER>
|
||||
#! </TRANSFORMERS>
|
||||
#! <FEAT_LINKS>
|
||||
#! <FEAT_LINK
|
||||
#! IDENTIFIER="5"
|
||||
#! SOURCE_NODE="9"
|
||||
#! TARGET_NODE="4"
|
||||
#! SOURCE_PORT_DESC="fo 0 RESULT"
|
||||
#! TARGET_PORT_DESC="-1"
|
||||
#! ENABLED="true"
|
||||
#! EXECUTION_IDX="0"
|
||||
#! HIDDEN="false"
|
||||
#! COLOUR="0,0,0,1"
|
||||
#! PEN_WIDTH="4"
|
||||
#! PEN_STYLE="1"
|
||||
#! LINK_STYLE_NAME="<Default>"
|
||||
#! EXTRA_POINTS=""
|
||||
#! />
|
||||
#! </FEAT_LINKS>
|
||||
#! <BREAKPOINTS>
|
||||
#! </BREAKPOINTS>
|
||||
#! <ATTR_LINKS>
|
||||
#! </ATTR_LINKS>
|
||||
#! <SUBDOCUMENTS>
|
||||
#! </SUBDOCUMENTS>
|
||||
#! <LOOKUP_TABLES>
|
||||
#! </LOOKUP_TABLES>
|
||||
#! </WORKSPACE>
|
||||
|
||||
FME_PYTHON_VERSION 38
|
||||
ARCGIS_COMPATIBILITY ARCGIS_AUTO
|
||||
GUI IGNORE DestDataset_CSV2_1,CSV2_OUT_DATASET_GROUP_CSV2_1,CSV2_OUT_EXTENSION_CSV2_1,CSV2_OUT_FIELDS_GROUP_CSV2_1,CSV2_OUT_DELIMITER_CSV2_1,CSV2_OUT_ENCODING_GROUP_CSV2_1,CSV2_OUT_ENCODING_CSV2_1,CSV2_OUT_WRITE_BOM_FOR_UNICODE_CSV2_1,CSV2_OUT_ADVANCED_GROUP_CSV2_1,CSV2_OUT_QUALIFY_FIELD_NAMES_CSV2_1,CSV2_OUT_QUALIFY_FIELD_VALUES_CSV2_1,CSV2_OUT_UNQUALIFIED_FIELD_VALUE_HANDLING_CSV2_1,CSV2_OUT_FIELD_QUALIFIER_CHARACTER_CSV2_1,CSV2_OUT_FIELD_QUALIFIER_ESCAPE_CHARACTER_CSV2_1,CSV2_OUT_ROW_TERMINATION_CSV2_1,CSV2_OUT_WRITE_SCHEMA_FILE_CSV2_1,CSV2_OUT_EXISTING_SCHEMA_FILE_HANDLING_CSV2_1
|
||||
# ============================================================================
|
||||
DEFAULT_MACRO DestDataset_CSV2 /Volumes/ker/mael/projets/osm_bzh/github/ar_redadeg/data/2021
|
||||
# ============================================================================
|
||||
GUI DIRNAME DestDataset_CSV2 Destination CSV (Comma Separated Value) Folder:
|
||||
# ============================================================================
|
||||
USER_PARAMETERS eyJwYXJhbWV0ZXJzIjpbeyJhY2Nlc3NNb2RlIjoid3JpdGUiLCJkZWZhdWx0VmFsdWUiOiIvVm9sdW1lcy9rZXIvbWFlbC9wcm9qZXRzL29zbV9iemgvZ2l0aHViL2FyX3JlZGFkZWcvZGF0YS8yMDIxIiwiaXRlbXNUb1NlbGVjdCI6ImZvbGRlcnMiLCJuYW1lIjoiRGVzdERhdGFzZXRfQ1NWMiIsInByb21wdCI6IkRlc3RpbmF0aW9uIENTViAoQ29tbWEgU2VwYXJhdGVkIFZhbHVlKSBGb2xkZXI6IiwicmVxdWlyZWQiOnRydWUsInNlbGVjdE11bHRpcGxlIjpmYWxzZSwidHlwZSI6ImZpbGUiLCJ2YWxpZGF0ZUV4aXN0ZW5jZSI6ZmFsc2UsInZhbHVlVHlwZSI6InN0cmluZyJ9XX0=
|
||||
# ============================================================================
|
||||
INCLUDE [ if {{$(DestDataset_CSV2)} == {}} { puts_real {Parameter 'DestDataset_CSV2' must be given a value.}; exit 1; }; ]
|
||||
#! START_HEADER
|
||||
#! START_WB_HEADER
|
||||
READER_TYPE MULTI_READER
|
||||
WRITER_TYPE MULTI_WRITER
|
||||
MULTI_WRITER_DATASET_ORDER BY_ID
|
||||
MULTI_WRITER_FIRST_WRITER_ID 0
|
||||
MULTI_WRITER_TYPE{0} CSV2
|
||||
MULTI_WRITER_KEYWORD{0} CSV2_1
|
||||
#! END_WB_HEADER
|
||||
#! START_WB_HEADER
|
||||
MACRO WB_KEYWORD "CSV2_1"
|
||||
#! END_WB_HEADER
|
||||
#! START_DEST_HEADER CSV2 CSV2_1
|
||||
# =====================================================================
|
||||
# The following GUI line prompts for a folder where the
|
||||
# CSV files will be stored
|
||||
#! END_DEST_HEADER
|
||||
#! START_WB_HEADER
|
||||
DEFAULT_MACRO DestDataset
|
||||
INCLUDE [ if {"$(DestDataset)" != ""} { \
|
||||
puts {DEFAULT_MACRO DestDataset_CSV2_1 $(DestDataset)} \
|
||||
} ]
|
||||
#! END_WB_HEADER
|
||||
#! START_DEST_HEADER CSV2 CSV2_1
|
||||
DEFAULT_MACRO DestDataset_CSV2_1 $(DestDataset_CSV2)
|
||||
GUI DIRNAME DestDataset_CSV2_1 Destination CSV (Comma Separated Value) Folder:
|
||||
DEFAULT_MACRO CSV2_OUT_DATASET_GROUP_CSV2_1
|
||||
GUI OPTIONAL DISCLOSUREGROUP CSV2_OUT_DATASET_GROUP_CSV2_1 CSV2_OUT_EXTENSION_CSV2_1%CSV2_OUT_EXISTING_FILE_HANDLING Dataset
|
||||
DEFAULT_MACRO CSV2_OUT_EXTENSION_CSV2_1 csv
|
||||
CSV2_1_EXTENSION "$(CSV2_OUT_EXTENSION_CSV2_1)"
|
||||
GUI OPTIONAL TEXT CSV2_OUT_EXTENSION_CSV2_1 Extension:
|
||||
DEFAULT_MACRO CSV2_OUT_EXISTING_FILE_HANDLING_CSV2_1 Yes
|
||||
CSV2_1_EXISTING_FILE_HANDLING "$(CSV2_OUT_EXISTING_FILE_HANDLING_CSV2_1)"
|
||||
DEFAULT_MACRO CSV2_OUT_FIELDS_GROUP_CSV2_1
|
||||
GUI OPTIONAL DISCLOSUREGROUP CSV2_OUT_FIELDS_GROUP_CSV2_1 CSV2_OUT_DELIMITER_CSV2_1%CSV2_OUT_WRITE_FIELD_NAMES Fields
|
||||
DEFAULT_MACRO CSV2_OUT_DELIMITER_CSV2_1 <comma>
|
||||
CSV2_1_DELIMITER "$(CSV2_OUT_DELIMITER_CSV2_1)"
|
||||
GUI STRING_OR_CHOICE_ENCODED CSV2_OUT_DELIMITER_CSV2_1 ,%;%|%space%tab Delimiter Character:
|
||||
DEFAULT_MACRO CSV2_OUT_WRITE_FIELD_NAMES_CSV2_1 firstrow
|
||||
CSV2_1_WRITE_FIELD_NAMES "$(CSV2_OUT_WRITE_FIELD_NAMES_CSV2_1)"
|
||||
DEFAULT_MACRO CSV2_OUT_ENCODING_GROUP_CSV2_1
|
||||
GUI OPTIONAL DISCLOSUREGROUP CSV2_OUT_ENCODING_GROUP_CSV2_1 CSV2_OUT_ENCODING_CSV2_1%CSV2_OUT_WRITE_BOM_FOR_UNICODE_CSV2_1 Encoding
|
||||
DEFAULT_MACRO CSV2_OUT_ENCODING_CSV2_1 UTF-8
|
||||
CSV2_1_ENCODING "$(CSV2_OUT_ENCODING_CSV2_1)"
|
||||
GUI STRING_OR_ENCODING CSV2_OUT_ENCODING_CSV2_1 fme-system%* Character Encoding:
|
||||
DEFAULT_MACRO CSV2_OUT_WRITE_BOM_FOR_UNICODE_CSV2_1 Yes
|
||||
CSV2_1_WRITE_BOM_FOR_UNICODE "$(CSV2_OUT_WRITE_BOM_FOR_UNICODE_CSV2_1)"
|
||||
GUI CHOICE CSV2_OUT_WRITE_BOM_FOR_UNICODE_CSV2_1 Yes%No Write Byte Order Mark for Unicode:
|
||||
DEFAULT_MACRO CSV2_OUT_ADVANCED_GROUP_CSV2_1
|
||||
GUI OPTIONAL DISCLOSUREGROUP CSV2_OUT_ADVANCED_GROUP_CSV2_1 FME_DISCLOSURE_CLOSED%CSV2_OUT_QUALIFY_FIELD_NAMES_CSV2_1%CSV2_OUT_QUALIFY_FIELD_VALUES_CSV2_1%CSV2_OUT_UNQUALIFIED_FIELD_VALUE_HANDLING_CSV2_1%CSV2_OUT_FIELD_QUALIFIER_CHARACTER_CSV2_1%CSV2_OUT_FIELD_QUALIFIER_ESCAPE_CHARACTER_CSV2_1%CSV2_OUT_ROW_TERMINATION_CSV2_1%CSV2_OUT_WRITE_SCHEMA_FILE_CSV2_1 Advanced
|
||||
DEFAULT_MACRO CSV2_OUT_QUALIFY_FIELD_NAMES_CSV2_1 if_needed
|
||||
CSV2_1_QUALIFY_FIELD_NAMES "$(CSV2_OUT_QUALIFY_FIELD_NAMES_CSV2_1)"
|
||||
GUI LOOKUP_CHOICE CSV2_OUT_QUALIFY_FIELD_NAMES_CSV2_1 Yes,yes%No,no%If<space>Needed,if_needed Qualify Field Names:
|
||||
DEFAULT_MACRO CSV2_OUT_QUALIFY_FIELD_VALUES_CSV2_1 if_needed
|
||||
CSV2_1_QUALIFY_FIELD_VALUES "$(CSV2_OUT_QUALIFY_FIELD_VALUES_CSV2_1)"
|
||||
GUI ACTIVECHOICE_LOOKUP CSV2_OUT_QUALIFY_FIELD_VALUES_CSV2_1 Yes,yes,CSV2_OUT_UNQUALIFIED_FIELD_VALUE_HANDLING_CSV2_1%No,no%If<space>Needed,if_needed,CSV2_OUT_UNQUALIFIED_FIELD_VALUE_HANDLING_CSV2_1 Qualify Field Values:
|
||||
DEFAULT_MACRO CSV2_OUT_UNQUALIFIED_FIELD_VALUE_HANDLING_CSV2_1 <Unused>
|
||||
CSV2_1_UNQUALIFIED_FIELD_VALUE_HANDLING "$(CSV2_OUT_UNQUALIFIED_FIELD_VALUE_HANDLING_CSV2_1)"
|
||||
GUI LOOKUP_CHOICE CSV2_OUT_UNQUALIFIED_FIELD_VALUE_HANDLING_CSV2_1 Remove<space>Unsafe<space>Characters,remove_unsafe%Preserve<space>Unsafe<space>Characters,preserve_unsafe Unqualified Field Value Handling:
|
||||
DEFAULT_MACRO CSV2_OUT_FIELD_QUALIFIER_CHARACTER_CSV2_1 <quote>
|
||||
CSV2_1_FIELD_QUALIFIER_CHARACTER "$(CSV2_OUT_FIELD_QUALIFIER_CHARACTER_CSV2_1)"
|
||||
GUI STRING_ENCODED CSV2_OUT_FIELD_QUALIFIER_CHARACTER_CSV2_1 Field Qualifier Character:
|
||||
DEFAULT_MACRO CSV2_OUT_FIELD_QUALIFIER_ESCAPE_CHARACTER_CSV2_1 <quote>
|
||||
CSV2_1_FIELD_QUALIFIER_ESCAPE_CHARACTER "$(CSV2_OUT_FIELD_QUALIFIER_ESCAPE_CHARACTER_CSV2_1)"
|
||||
GUI STRING_ENCODED CSV2_OUT_FIELD_QUALIFIER_ESCAPE_CHARACTER_CSV2_1 Field Qualifier Escape Character:
|
||||
DEFAULT_MACRO CSV2_OUT_ROW_TERMINATION_CSV2_1 System
|
||||
CSV2_1_ROW_TERMINATION "$(CSV2_OUT_ROW_TERMINATION_CSV2_1)"
|
||||
GUI CHOICE CSV2_OUT_ROW_TERMINATION_CSV2_1 System%Windows%Unix%Macintosh Row Termination:
|
||||
DEFAULT_MACRO CSV2_OUT_WRITE_SCHEMA_FILE_CSV2_1 NO
|
||||
CSV2_1_WRITE_SCHEMA_FILE "$(CSV2_OUT_WRITE_SCHEMA_FILE_CSV2_1)"
|
||||
GUI ACTIVEDISCLOSUREGROUP CSV2_OUT_WRITE_SCHEMA_FILE_CSV2_1 FME_DISCLOSURE_CLOSED%CSV2_OUT_EXISTING_SCHEMA_FILE_HANDLING_CSV2_1 Write Schema Configuration File
|
||||
DEFAULT_MACRO CSV2_OUT_EXISTING_SCHEMA_FILE_HANDLING_CSV2_1 <Unused>
|
||||
CSV2_1_EXISTING_SCHEMA_FILE_HANDLING "$(CSV2_OUT_EXISTING_SCHEMA_FILE_HANDLING_CSV2_1)"
|
||||
GUI CHOICE CSV2_OUT_EXISTING_SCHEMA_FILE_HANDLING_CSV2_1 Overwrite%Prepend Existing Schema File Handling:
|
||||
DEFAULT_MACRO CSV2_OUT_COORDINATE_SYSTEM_GRANULARITY_CSV2_1 FEATURE_TYPE
|
||||
CSV2_1_COORDINATE_SYSTEM_GRANULARITY "$(CSV2_OUT_COORDINATE_SYSTEM_GRANULARITY_CSV2_1)"
|
||||
# ============================================================================
|
||||
CSV2_1_GENERATE_FME_BUILD_NUM 21306
|
||||
CSV2_1_DATASET "$(DestDataset_CSV2_1)"
|
||||
#! END_DEST_HEADER
|
||||
#! START_WB_HEADER
|
||||
#! END_WB_HEADER
|
||||
#! END_HEADER
|
||||
|
||||
LOG_FILENAME "$(FME_MF_DIR)export_prefecture_liste_voies.log"
|
||||
LOG_APPEND NO
|
||||
LOG_FILTER_MASK -1
|
||||
LOG_MAX_FEATURES 200
|
||||
LOG_MAX_RECORDED_FEATURES 200
|
||||
FME_REPROJECTION_ENGINE FME
|
||||
FME_IMPLICIT_CSMAP_REPROJECTION_MODE Auto
|
||||
FME_GEOMETRY_HANDLING Enhanced
|
||||
FME_STROKE_MAX_DEVIATION 0
|
||||
FME_NAMES_ENCODING UTF-8
|
||||
DEFAULT_MACRO DATASET_KEYWORD_CSV2_1 CSV2_1
|
||||
# -------------------------------------------------------------------------
|
||||
|
||||
MULTI_READER_CONTINUE_ON_READER_FAILURE No
|
||||
|
||||
# -------------------------------------------------------------------------
|
||||
|
||||
MACRO WORKSPACE_NAME export_prefecture_liste_voies
|
||||
MACRO FME_VIEWER_APP fmedatainspector
|
||||
DEFAULT_MACRO WB_CURRENT_CONTEXT
|
||||
# -------------------------------------------------------------------------
|
||||
MACRO SQLCreator_DIRECTIVES NAMED_CONNECTION bed110<at>redadeg_2021<at>redadeg
|
||||
FACTORY_DEF {*} CreationFactory FACTORY_NAME { SQLCreator_Creator } OUTPUT { FEATURE_TYPE _____CREATED______ }
|
||||
FACTORY_DEF {*} QueryFactory FACTORY_NAME { SQLCreator } INPUT FEATURE_TYPE _____CREATED______ QUERY_SQL { SELECT<lf><space><space>left<openparen>com.insee<comma>2<closeparen><space>as<space>dpt<comma><lf><space><space>com.insee<comma><space>com.nom<comma><lf><space><space>pk.pk_id<comma><space>pk.way_ref<space>as<space>voie_ref<comma><lf><space><space>CASE<lf><space><space><space><space>WHEN<space>way_name_fr<space>IS<space>NULL<space>THEN<space><apos><openparen>voie<space>non<space>d<u00e9>nomm<u00e9>e<closeparen><apos><lf><tab>ELSE<space>way_name_fr<lf><space><space>END<space>as<space>voie_nom<lf>FROM<space>phase_3_pk_auto<space>pk<comma><space>osm_communes<space>com<lf>WHERE<space>ST_Intersects<openparen>pk.the_geom<comma>com.the_geom<closeparen><lf>ORDER<space>BY<space>pk_id } COMBINE_ATTRIBUTES RESULT_ONLY COMBINE_GEOMETRY RESULT_ONLY READER_TYPE { POSTGRES } READER_DATASET { "bed110<at>redadeg_2021<at>redadeg" } READER_PARAMS { $(SQLCreator_DIRECTIVES) } QUERYFCT_PROPAGATE_IDS_ON_SQL_EXECUTE YES CONTINUE_ON_READER_ERROR YES OUTPUT { RESULT FEATURE_TYPE SQLCreator_RESULT @SupplyAttributes(fme_feature_type,SQLCreator) } OUTPUT { READER_ERROR FEATURE_TYPE SQLCreator_<REJECTED> }
|
||||
FACTORY_DEF * BranchingFactory FACTORY_NAME "SQLCreator_RESULT Brancher -1 5" INPUT FEATURE_TYPE SQLCreator_RESULT TARGET_FACTORY "$(WB_CURRENT_CONTEXT)_CREATOR_BRANCH_TARGET" MAXIMUM_COUNT None OUTPUT PASSED FEATURE_TYPE *
|
||||
DEFAULT_MACRO _WB_BYPASS_TERMINATION No
|
||||
FACTORY_DEF * TeeFactory FACTORY_NAME SQLCreator_<Rejected> INPUT FEATURE_TYPE SQLCreator_<REJECTED> OUTPUT FAILED FEATURE_TYPE * @Abort(ENCODED, SQLCreator<space>output<space>a<space><lt>Rejected<gt><space>feature.<space><space>To<space>continue<space>translation<space>when<space>features<space>are<space>rejected<comma><space>change<space><apos>Workspace<space>Parameters<apos><space><gt><space>Translation<space><gt><space><apos>Rejected<space>Feature<space>Handling<apos><space>to<space><apos>Continue<space>Translation<apos>)
|
||||
# -------------------------------------------------------------------------
|
||||
FACTORY_DEF * TeeFactory FACTORY_NAME "$(WB_CURRENT_CONTEXT)_CREATOR_BRANCH_TARGET" INPUT FEATURE_TYPE * OUTPUT FEATURE_TYPE *
|
||||
# -------------------------------------------------------------------------
|
||||
|
||||
FACTORY_DEF * RoutingFactory FACTORY_NAME "Destination Feature Type Routing Correlator" COMMAND_PARM_EVALUATION SINGLE_PASS INPUT FEATURE_TYPE * ROUTE FME_GENERIC SQLCreator_RESULT TO CSV2 __GO_TO_FINAL_OUTPUT_ROUTER__ multi_writer_id,0,<at>SupplyAttributes<openparen>ENCODED<comma>__wb_out_feat_type__<comma>ar_redadeg_prefecture<closeparen> GEOMETRY FEATURE_TYPE_ATTRIBUTE __wb_out_feat_type__ OUTPUT ROUTED FEATURE_TYPE * OUTPUT NOT_ROUTED FEATURE_TYPE __nuke_me__ @Tcl2("FME_StatMessage 818059 [FME_GetAttribute fme_template_feature_type] 818060 818061 fme_warn")
|
||||
# -------------------------------------------------------------------------
|
||||
|
||||
FACTORY_DEF * TeeFactory FACTORY_NAME "Final Output Nuker" INPUT FEATURE_TYPE __nuke_me__
|
||||
|
||||
# -------------------------------------------------------------------------
|
||||
CSV2_1_DEF ar_redadeg_prefecture csv_existing_file_handling Yes csv_write_field_names firstrow dpt string insee string nom string pk_id string voie_ref string voie_nom string
|
|
@ -1,40 +0,0 @@
|
|||
#!/bin/bash
|
||||
|
||||
set -e
|
||||
set -u
|
||||
|
||||
PSQL=/usr/bin/psql
|
||||
DB_HOST=localhost
|
||||
DB_NAME=redadeg_$millesime
|
||||
DB_USER=redadeg
|
||||
DB_PASSWD=redadeg
|
||||
|
||||
# ce script récupère une couche des communes de France et la charge dans la base de données
|
||||
|
||||
cd data
|
||||
|
||||
# récupérer la couche communales OSM
|
||||
# https://www.data.gouv.fr/fr/datasets/decoupage-administratif-communal-francais-issu-d-openstreetmap/
|
||||
wget http://tile.openstreetmap.bzh/data/br/osm_br_municipalities.geojson
|
||||
#wget pour voir la progression
|
||||
|
||||
ogr2ogr -f "PostgreSQL" PG:"host=$DB_HOST user=$DB_USER password=$DB_PASSWD dbname=$DB_NAME" osm_br_municipalities.geojson -nln osm_communes_4326 -lco GEOMETRY_NAME=the_geom -explodecollections -overwrite
|
||||
|
||||
|
||||
# passer la couche de WGS84 en Lambert93
|
||||
$PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME -c "TRUNCATE TABLE osm_communes ;"
|
||||
$PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME -c "
|
||||
INSERT INTO osm_communes
|
||||
SELECT
|
||||
ogc_fid,
|
||||
insee,
|
||||
nom,
|
||||
wikipedia,
|
||||
surf_ha,
|
||||
ST_Transform(ST_SetSRID(the_geom,4326),2154) AS the_geom
|
||||
FROM osm_communes_4326
|
||||
WHERE left(insee,2) IN ('22','29','35','44','56')
|
||||
ORDER BY insee ASC ;"
|
||||
$PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME -c "VACUUM FULL osm_communes;"
|
||||
|
||||
|
|
@ -1,44 +0,0 @@
|
|||
#!/bin/bash
|
||||
|
||||
set -e
|
||||
set -u
|
||||
|
||||
millesime=2022
|
||||
|
||||
PSQL=/usr/bin/psql
|
||||
DB_HOST=localhost
|
||||
DB_NAME=redadeg_$millesime
|
||||
DB_USER=redadeg
|
||||
DB_PASSWD=redadeg
|
||||
|
||||
# ce script récupère une couche des communes de France et la charge dans la base de données
|
||||
|
||||
cd ../data/$millesime/
|
||||
|
||||
# récupérer la couche communales OSM
|
||||
# https://www.data.gouv.fr/fr/datasets/decoupage-administratif-communal-francais-issu-d-openstreetmap/
|
||||
#curl -sS http://osm13.openstreetmap.fr/~cquest/openfla/export/communes-20210101-shp.zip > communes-20210101-shp.zip
|
||||
wget http://osm13.openstreetmap.fr/~cquest/openfla/export/communes-20210101-shp.zip
|
||||
|
||||
unzip -o communes-20210101-shp.zip
|
||||
|
||||
ogr2ogr -f "PostgreSQL" PG:"host=$DB_HOST user=$DB_USER password=$DB_PASSWD dbname=$DB_NAME" communes-20210101.shp -nln osm_communes_4326 -lco GEOMETRY_NAME=the_geom -explodecollections -overwrite
|
||||
|
||||
|
||||
# passer la couche de WGS84 en Lambert93
|
||||
$PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME -c "TRUNCATE TABLE osm_communes ;"
|
||||
$PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME -c "
|
||||
INSERT INTO osm_communes
|
||||
SELECT
|
||||
ogc_fid,
|
||||
insee,
|
||||
nom,
|
||||
wikipedia,
|
||||
surf_ha,
|
||||
ST_Transform(ST_SetSRID(the_geom,4326),2154) AS the_geom
|
||||
FROM osm_communes_4326
|
||||
WHERE left(insee,2) IN ('22','29','35','44','56')
|
||||
ORDER BY insee ASC ;"
|
||||
$PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME -c "VACUUM FULL osm_communes;"
|
||||
|
||||
|
File diff suppressed because it is too large
Load diff
|
@ -1,34 +0,0 @@
|
|||
#!/bin/bash
|
||||
|
||||
set -e
|
||||
set -u
|
||||
|
||||
# argument 1 = millesime redadeg
|
||||
millesime=$1
|
||||
|
||||
PSQL=/usr/bin/psql
|
||||
DB_HOST=localhost
|
||||
DB_NAME=redadeg_$millesime
|
||||
DB_USER=redadeg
|
||||
DB_PASSWD=redadeg
|
||||
|
||||
rep_scripts='/data/projets/ar_redadeg/scripts/'
|
||||
echo "rep_scripts = $rep_scripts"
|
||||
# variables liées au millésimes
|
||||
echo "millesime de travail = $1"
|
||||
rep_data=../data/$millesime
|
||||
echo "rep_data = $rep_data"
|
||||
echo "base de données = $DB_NAME"
|
||||
echo ""
|
||||
|
||||
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " Patch de la couche de routage sur des secteurs particuliers"
|
||||
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME < patch_osm_roads_pgr.sql
|
||||
|
||||
echo ""
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " F I N patch"
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo ""
|
|
@ -1,40 +0,0 @@
|
|||
|
||||
|
||||
|
||||
-- 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
|
||||
-- on crée un identifiant négatif
|
||||
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 ;
|
||||
|
||||
|
||||
-- recrée des nœuds uniquement sur les zones de patch
|
||||
SELECT pgr_nodeNetwork('osm_roads_pgr', 0.001, rows_where := 'id < 0');
|
||||
|
||||
-- recalcul la topologie pgRouting uniquement sur les zones de patch
|
||||
SELECT pgr_createTopology('osm_roads_pgr', 0.001, rows_where := 'id < 0', clean := false);
|
||||
|
||||
|
||||
-- recalcul toute la topologie pgRouting en renumérotant de zéro
|
||||
--SELECT pgr_createTopology('osm_roads_pgr', 0.001, clean := true);
|
||||
|
||||
--SELECT pgr_analyzegraph('osm_roads_pgr', 0.001);
|
File diff suppressed because it is too large
Load diff
File diff suppressed because it is too large
Load diff
|
@ -1,128 +0,0 @@
|
|||
|
||||
|
||||
WITH ref AS (
|
||||
SELECT COUNT(pk_id) as ref FROM phase_5_pk_ref
|
||||
WHERE (secteur_id >= 10 and secteur_id < 20)
|
||||
),
|
||||
umap AS (
|
||||
SELECT COUNT(pk_id) as umap FROM phase_5_pk_umap
|
||||
WHERE (secteur_id >= 10 and secteur_id < 20)
|
||||
)
|
||||
SELECT
|
||||
*,
|
||||
CASE
|
||||
WHEN ref.ref < umap.umap THEN 'plus'
|
||||
WHEN ref.ref > umap.umap THEN 'moins'
|
||||
WHEN ref.ref = umap.umap THEN 'égalité'
|
||||
ELSE 'problème'
|
||||
END AS test
|
||||
FROM ref, umap
|
||||
|
||||
|
||||
-- test de géométrie import umap
|
||||
SELECT secteur_id, pk_id, ST_geometrytype(the_geom) FROM phase_5_pk_umap
|
||||
WHERE ST_geometrytype(the_geom) <> 'ST_Point' OR secteur_id IS NULL OR pk_id IS NULL ;
|
||||
|
||||
|
||||
|
||||
-- test de distance PK ref -> pk umap
|
||||
SELECT
|
||||
--COUNT(*)
|
||||
r.pk_id,
|
||||
r.secteur_id,
|
||||
TRUNC(ST_Distance(ST_Transform(r.the_geom,2154), ST_Transform(u.the_geom,2154))::numeric,2) as distance
|
||||
FROM phase_5_pk_ref r FULL JOIN phase_5_pk_umap u ON r.pk_id = u.pk_id
|
||||
WHERE
|
||||
TRUNC(ST_Distance(ST_Transform(r.the_geom,2154), ST_Transform(u.the_geom,2154))::numeric,2) > 1
|
||||
--ORDER BY r.secteur_id, r.pk_id
|
||||
ORDER BY TRUNC(ST_Distance(ST_Transform(r.the_geom,2154), ST_Transform(u.the_geom,2154))::numeric,2) desc
|
||||
|
||||
|
||||
WITH liste_pk_decales AS (
|
||||
SELECT
|
||||
r.pk_id,
|
||||
r.secteur_id,
|
||||
TRUNC(ST_Distance(ST_Transform(r.the_geom,2154), ST_Transform(u.the_geom,2154))::numeric,2) as distance
|
||||
FROM phase_5_pk_ref r FULL JOIN phase_5_pk_umap u ON r.pk_id = u.pk_id
|
||||
WHERE TRUNC(ST_Distance(ST_Transform(r.the_geom,2154), ST_Transform(u.the_geom,2154))::numeric,2) > 1
|
||||
)
|
||||
SELECT '1' as tri, '> 1000' as distance, COUNT(*) FROM liste_pk_decales WHERE (distance >= 1000)
|
||||
UNION SELECT '2' as tri, '> 500' as distance, COUNT(*) FROM liste_pk_decales WHERE (distance >= 500 AND distance < 1000)
|
||||
UNION SELECT '3' as tri, '> 100' as distance, COUNT(*) FROM liste_pk_decales WHERE (distance >= 100 AND distance < 500)
|
||||
UNION SELECT '4' as tri, '> 10' as distance, COUNT(*) FROM liste_pk_decales WHERE (distance >= 10 AND distance < 100)
|
||||
UNION SELECT '5' as tri, '< 10' as distance, COUNT(*) FROM liste_pk_decales WHERE (distance < 10)
|
||||
ORDER BY tri ;
|
||||
|
||||
|
||||
|
||||
|
||||
-- ligne entre les PK recalés et les PK références
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
-- recalage des PK umap sur le trace
|
||||
WITH
|
||||
pk_decales AS (
|
||||
SELECT
|
||||
r.pk_id,
|
||||
r.secteur_id,
|
||||
TRUNC(ST_Distance(r.the_geom, u.the_geom)::numeric,2) as distance,
|
||||
u.the_geom
|
||||
FROM phase_5_pk_ref r FULL JOIN phase_5_pk_umap u ON r.pk_id = u.pk_id
|
||||
WHERE TRUNC(ST_Distance(r.the_geom, u.the_geom)::numeric,2) > 1
|
||||
AND r.secteur_id = 20
|
||||
),
|
||||
buffer_troncons AS (
|
||||
SELECT troncon_id, ST_BUFFER(the_geom, 5) as the_geom
|
||||
FROM phase_3_trace_troncons
|
||||
WHERE secteur_id = 20
|
||||
)
|
||||
|
||||
SELECT
|
||||
pk.pk_id, pk.the_geom,
|
||||
ST_Distance(pk.the_geom, ST_ClosestPoint(trace.the_geom, pk.the_geom)) AS distance,
|
||||
ST_Snap(
|
||||
pk.the_geom, -- le point d'origine à recaler
|
||||
ST_ClosestPoint(trace.the_geom, pk.the_geom), -- le point le plus près dans la couche de nœuds
|
||||
ST_Distance(pk.the_geom, ST_ClosestPoint(trace.the_geom, pk.the_geom))* 1.01 -- dans la distance de ce plus proche point
|
||||
) AS the_geom
|
||||
FROM pk_decales pk, phase_3_trace_troncons trace, buffer_troncons
|
||||
WHERE ST_INTERSECTS(pk.the_geom, buffer_troncons.the_geom)
|
||||
AND trace.secteur_id = 20
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
WITH
|
||||
pk_decales AS (
|
||||
SELECT
|
||||
r.pk_id,
|
||||
r.secteur_id,
|
||||
TRUNC(ST_Distance(r.the_geom, u.the_geom)::numeric,2) as distance_pk_ref,
|
||||
u.the_geom
|
||||
FROM phase_5_pk_ref r FULL JOIN phase_5_pk_umap u ON r.pk_id = u.pk_id
|
||||
WHERE TRUNC(ST_Distance(r.the_geom, u.the_geom)::numeric,2) > 1
|
||||
),
|
||||
trace AS (
|
||||
SELECT
|
||||
troncon_id,
|
||||
ST_LineMerge(the_geom) AS the_geom
|
||||
FROM phase_3_trace_troncons
|
||||
WHERE secteur_id = 60
|
||||
)
|
||||
-- il faut qu'on commence par limiter au tronçon le plus près du PK
|
||||
SELECT
|
||||
pk.pk_id,
|
||||
pk.the_geom AS pk_point,
|
||||
trace.the_geom AS trace,
|
||||
|
||||
FROM pk_decales pk, trace
|
||||
WHERE ST_INTERSECTS(trace.the_geom, ST_BUFFER(pk.the_geom,2) )
|
||||
|
||||
|
||||
|
||||
|
||||
|
File diff suppressed because it is too large
Load diff
|
@ -1,125 +0,0 @@
|
|||
|
||||
/*
|
||||
==========================================================================
|
||||
|
||||
phase 2 : préparation pour le calcul d'itinéraires en appui du réseau routier OSM
|
||||
|
||||
==========================================================================
|
||||
*/
|
||||
|
||||
-- dans la base redadeg on a chargé la couche osm_roads qui a été calculée
|
||||
-- à partir de données OSM
|
||||
|
||||
-- on efface la topologie existante
|
||||
SELECT DropTopology('osm_roads_topo') ;
|
||||
|
||||
-- 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);
|
||||
|
||||
-- 2. ajout d'un nouvel attribut sur la table osm_roads
|
||||
SELECT topology.AddTopoGeometryColumn('osm_roads_topo', 'public', 'osm_roads', 'topo_geom', 'LINESTRING');
|
||||
|
||||
|
||||
-- on a donc un nouveau schéma osm_roads_topo qui contient 4 tables : edge_data, face, node, relation
|
||||
-- et un nouvel enregistrement dans la table topology.layer
|
||||
-- logiquement : c'est 1
|
||||
SELECT layer_id FROM topology.layer WHERE table_name = 'osm_roads' ;
|
||||
|
||||
|
||||
-- 3. on calcule le graphe topologique
|
||||
-- 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, 0.00001);
|
||||
|
||||
/*
|
||||
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
|
||||
|
||||
|
||||
-- 4. remplissage de la couche routable depuis la couche d'origine et la topologie
|
||||
INSERT INTO osm_roads_pgr
|
||||
( SELECT
|
||||
row_number() over() as id,
|
||||
o.osm_id,
|
||||
o.highway,
|
||||
o.type,
|
||||
o.oneway,
|
||||
o.ref,
|
||||
o.name_fr,
|
||||
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,
|
||||
osm_roads o
|
||||
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), reverse_cost = st_length(the_geom);
|
||||
|
||||
|
||||
-- 5. calcul du graphe routier par pgRouting
|
||||
SELECT pgr_createTopology('osm_roads_pgr', 1.0);
|
||||
|
||||
-- vérification
|
||||
SELECT pgr_analyzegraph('osm_roads_pgr', 1.0);
|
||||
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, 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 ;
|
||||
|
||||
|
||||
|
||||
-- permissions
|
||||
ALTER SCHEMA osm_roads_topo OWNER TO redadeg ;
|
||||
ALTER TABLE osm_roads_topo.edge_data OWNER TO redadeg ;
|
||||
ALTER TABLE osm_roads_topo.face OWNER TO redadeg ;
|
||||
ALTER TABLE osm_roads_topo.node OWNER TO redadeg ;
|
||||
ALTER TABLE osm_roads_topo.relation OWNER TO redadeg ;
|
||||
ALTER VIEW osm_roads_topo.edge OWNER TO redadeg ;
|
||||
ALTER SEQUENCE osm_roads_topo.layer_id_seq OWNER TO redadeg ;
|
||||
ALTER SEQUENCE osm_roads_topo.topogeo_s_1 OWNER TO redadeg ;
|
||||
|
||||
|
|
@ -1,34 +0,0 @@
|
|||
#!/bin/bash
|
||||
|
||||
cd data
|
||||
|
||||
# dump des tables de routage
|
||||
|
||||
pg_dump --file osm_roads_pgr.sql --host localhost --port 5432 --username redadeg \
|
||||
--no-password --verbose --format=p --no-owner --section=pre-data --section=data --no-privileges --no-tablespaces --no-unlogged-table-data --no-comments \
|
||||
--table public.osm_roads_pgr redadeg
|
||||
|
||||
pg_dump --file osm_roads_pgr_noded.sql --host localhost --port 5432 --username redadeg \
|
||||
--no-password --verbose --format=p --no-owner --section=pre-data --section=data --no-privileges --no-tablespaces --no-unlogged-table-data --no-comments \
|
||||
--table public.osm_roads_pgr_noded redadeg
|
||||
|
||||
pg_dump --file osm_roads_pgr_vertices_pgr.sql --host localhost --port 5432 --username redadeg \
|
||||
--no-password --verbose --format=p --no-owner --section=pre-data --section=data --no-privileges --no-tablespaces --no-unlogged-table-data --no-comments \
|
||||
--table public.osm_roads_pgr_vertices_pgr redadeg
|
||||
|
||||
|
||||
# on zippe
|
||||
rm osm_roads_pgr.zip
|
||||
zip osm_roads_pgr.zip osm_roads_pgr.sql osm_roads_pgr_noded.sql osm_roads_pgr_vertices_pgr.sql
|
||||
|
||||
# on envoi sur le serveur
|
||||
rsync -av --progress osm_roads_pgr.zip breizhpovh2:/data/www/vhosts/ar-redadeg_openstreetmap_bzh/htdocs/scripts/data/
|
||||
|
||||
# on envoie des commande pour maj les tables de routage
|
||||
ssh breizhpovh2 "cd /data/www/vhosts/ar-redadeg_openstreetmap_bzh/htdocs/scripts/data/ ; \
|
||||
unzip osm_roads_pgr.zip ; \
|
||||
psql -U redadeg -d redadeg -c 'DROP TABLE IF EXISTS osm_roads_pgr; DROP TABLE IF EXISTS osm_roads_pgr_noded; DROP TABLE IF EXISTS osm_roads_pgr_vertices_pgr;' ; \
|
||||
psql -U redadeg -d redadeg < osm_roads_pgr.sql ; \
|
||||
psql -U redadeg -d redadeg < osm_roads_pgr_noded.sql ; \
|
||||
psql -U redadeg -d redadeg < osm_roads_pgr_vertices_pgr.sql ;\
|
||||
rm -f osm_roads_pgr.sql osm_roads_pgr_noded.sql osm_roads_pgr_vertices_pgr.sql ;"
|
|
@ -1,82 +0,0 @@
|
|||
#!/usr/bin/env python3
|
||||
# -*- coding: utf-8 -*-
|
||||
|
||||
import os
|
||||
import configparser
|
||||
import argparse
|
||||
from argparse import RawTextHelpFormatter
|
||||
import psycopg2
|
||||
|
||||
|
||||
# +++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++
|
||||
# +++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++
|
||||
# +++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++
|
||||
|
||||
|
||||
|
||||
def initVariables():
|
||||
|
||||
# lecture du fichier de configuration qui contient les infos de connection aux bases de données
|
||||
config = configparser.ConfigParser()
|
||||
config.read('config.ini')
|
||||
|
||||
# enregistrement en variables
|
||||
pg_host = config['pg_redadeg']['host']
|
||||
pg_port = config['pg_redadeg']['port']
|
||||
pg_db = config['pg_redadeg']['db'] + "_" + millesime
|
||||
pg_user = config['pg_redadeg']['user']
|
||||
pg_passwd = config['pg_redadeg']['passwd']
|
||||
|
||||
# chaîne de connexion Postgres
|
||||
global PG_ConnString
|
||||
PG_ConnString = "host="+ pg_host + " port="+ pg_port +" dbname="+ pg_db +" user="+ pg_user +" password="+ pg_passwd
|
||||
#print(PG_ConnString)
|
||||
|
||||
|
||||
|
||||
# +++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++
|
||||
# +++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++
|
||||
# +++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++
|
||||
|
||||
|
||||
def main():
|
||||
|
||||
# variables globales
|
||||
global millesime
|
||||
global PG_ConnString
|
||||
|
||||
# millesime forcé
|
||||
millesime = "2022"
|
||||
|
||||
initVariables()
|
||||
|
||||
|
||||
# connection à la base
|
||||
try:
|
||||
# connexion à la base, si plante, on sort
|
||||
conn = psycopg2.connect(PG_ConnString)
|
||||
cursor = conn.cursor()
|
||||
|
||||
except:
|
||||
print( "connexion à la base impossible")
|
||||
|
||||
|
||||
# déconnection de la base
|
||||
try:
|
||||
cursor.close()
|
||||
conn.close()
|
||||
except:
|
||||
print("")
|
||||
|
||||
|
||||
print( "")
|
||||
print( " F I N")
|
||||
|
||||
return
|
||||
|
||||
|
||||
if __name__ == "__main__":
|
||||
# execute only if run as a script
|
||||
main()
|
||||
|
||||
|
|
@ -1,102 +0,0 @@
|
|||
#!/bin/bash
|
||||
|
||||
set -e
|
||||
set -u
|
||||
|
||||
# argument 1 = millesime redadeg
|
||||
millesime=$1
|
||||
|
||||
PSQL=/usr/bin/psql
|
||||
DB_HOST=localhost
|
||||
DB_NAME=redadeg_$millesime
|
||||
DB_USER=redadeg
|
||||
DB_PASSWD=redadeg
|
||||
|
||||
rep_scripts='/data/projets/ar_redadeg/scripts/'
|
||||
echo "rep_scripts = $rep_scripts"
|
||||
# variables liées au millésimes
|
||||
echo "millesime de travail = $1"
|
||||
rep_data=../data/$millesime
|
||||
echo "rep_data = $rep_data"
|
||||
echo "base de données = $DB_NAME"
|
||||
echo ""
|
||||
|
||||
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " Récupération des fichiers geojson depuis umap"
|
||||
|
||||
# traitement des tracés manuels
|
||||
|
||||
# on commence par supprimer la table
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME -c "DROP TABLE IF EXISTS phase_1_trace_3857 CASCADE;"
|
||||
#$PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME -c "DROP TABLE IF EXISTS phase_1_pk_vip_3857;"
|
||||
echo ""
|
||||
|
||||
|
||||
# on va lire le fichier de config des couches umap pour boucler
|
||||
IFS="="
|
||||
while read -r line
|
||||
do
|
||||
layer=$line
|
||||
|
||||
echo " umap layer id = $layer"
|
||||
wget -q -O $rep_data/phase_1_umap_trace_$layer.geojson https://umap.openstreetmap.fr/fr/datalayer/$layer
|
||||
echo " recup ok"
|
||||
|
||||
# on charge dans postgis
|
||||
# note : les coordonnées sont en 3857 mais la déclaration de la table = 4326
|
||||
|
||||
echo " chargement dans la couche d'import"
|
||||
ogr2ogr -f "PostgreSQL" PG:"host=$DB_HOST user=$DB_USER password=$DB_PASSWD dbname=$DB_NAME" $rep_data/phase_1_umap_trace_$layer.geojson -nln phase_1_trace_3857 -lco GEOMETRY_NAME=the_geom -explodecollections
|
||||
echo " fait"
|
||||
echo ""
|
||||
|
||||
|
||||
# fin de la boucle de lecture des layers umap
|
||||
done < $rep_data/umap_phase_1_layers.txt
|
||||
|
||||
|
||||
# PK VIP
|
||||
# pas besoin en 2021
|
||||
#ogr2ogr -f "PostgreSQL" PG:"host=$DB_HOST user=$DB_USER password=$DB_PASSWD dbname=$DB_NAME" data/phase_1_umap_pk_vip.geojson -nln phase_1_pk_vip_3857 -lco GEOMETRY_NAME=the_geom -explodecollections -overwrite
|
||||
|
||||
|
||||
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " Application des traitements SQL "
|
||||
echo ""
|
||||
|
||||
# on crée les tables en 3948
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME < $rep_scripts/traitements_phase_1.sql
|
||||
|
||||
echo " fait"
|
||||
echo ""
|
||||
|
||||
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " Exports "
|
||||
echo ""
|
||||
|
||||
echo " exports geojson"
|
||||
echo ""
|
||||
|
||||
# et on exporte vers Geojson
|
||||
rm -f $rep_data/phase_1_pk_auto.geojson
|
||||
ogr2ogr -f "GeoJSON" $rep_data/phase_1_pk_auto.geojson PG:"host=$DB_HOST user=$DB_USER password=$DB_PASSWD dbname=$DB_NAME" phase_1_pk_auto_4326
|
||||
rm -f $rep_data/phase_1_trace_4326.geojson
|
||||
ogr2ogr -f "GeoJSON" $rep_data/phase_1_trace_4326.geojson PG:"host=$DB_HOST user=$DB_USER password=$DB_PASSWD dbname=$DB_NAME" phase_1_trace_4326
|
||||
# les fichiers sont ensuite tout de suite visible dans umap
|
||||
|
||||
# exports supplémentaires
|
||||
rm -f $rep_data/phase_1_pk_auto.xlsx
|
||||
ogr2ogr -f "XLSX" $rep_data/phase_1_pk_auto.xlsx PG:"host=$DB_HOST user=$DB_USER password=$DB_PASSWD dbname=$DB_NAME" phase_1_pk_auto_4326
|
||||
|
||||
echo " fait"
|
||||
echo ""
|
||||
|
||||
echo ""
|
||||
echo ""
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " F I N traitements phase 1"
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo ""
|
|
@ -1,81 +0,0 @@
|
|||
|
||||
|
||||
TRUNCATE phase_1_trace ;
|
||||
INSERT INTO phase_1_trace
|
||||
SELECT
|
||||
ogc_fid,
|
||||
secteur_id::int,
|
||||
ordre::int,
|
||||
0 AS longueur,
|
||||
ST_Transform(the_geom,2154) AS the_geom
|
||||
FROM phase_1_trace_3857
|
||||
WHERE ST_LENGTH(the_geom) > 0
|
||||
ORDER BY secteur_id ASC, ordre ASC ;
|
||||
|
||||
-- mise à jour de la longueur 1 fois la géométrie passée en CC48
|
||||
UPDATE phase_1_trace
|
||||
SET longueur = TRUNC( ST_Length(the_geom)::numeric / 1000 , 2) ;
|
||||
|
||||
|
||||
-- on remplit la table trace 4326 pour exporter vers umap
|
||||
TRUNCATE phase_1_trace_4326 ;
|
||||
INSERT INTO phase_1_trace_4326
|
||||
SELECT
|
||||
t.ogc_fid,
|
||||
s.nom_br AS name,
|
||||
t.secteur_id::int,
|
||||
t.ordre::int,
|
||||
t.longueur,
|
||||
ST_Transform(t.the_geom,4326) AS the_geom
|
||||
FROM phase_1_trace t JOIN secteur s ON t.secteur_id = s.id
|
||||
ORDER BY secteur_id ASC, ordre ASC ;
|
||||
|
||||
|
||||
|
||||
-- TRUNCATE phase_1_pk_vip ;
|
||||
-- INSERT INTO phase_1_pk_vip
|
||||
-- SELECT ogc_fid, name, '', ST_Transform(the_geom,2154) AS the_geom
|
||||
-- FROM phase_1_pk_vip_3857 ;
|
||||
|
||||
|
||||
|
||||
TRUNCATE phase_1_trace_troncons ;
|
||||
INSERT INTO phase_1_trace_troncons
|
||||
SELECT
|
||||
row_number() over() as uid,
|
||||
secteur_id,
|
||||
ordre,
|
||||
NULL AS km,
|
||||
NULL AS km_reel,
|
||||
NULL AS longueur,
|
||||
ST_LineSubstring(the_geom, 1000.00*n/length,
|
||||
CASE
|
||||
WHEN 1000.00*(n+1) < length THEN 1000.00*(n+1)/length
|
||||
ELSE 1
|
||||
END) AS the_geom
|
||||
FROM
|
||||
(SELECT
|
||||
ogc_fid,
|
||||
secteur_id,
|
||||
ordre,
|
||||
ST_LineMerge(the_geom)::geometry(LineString,2154) AS the_geom,
|
||||
ST_Length(the_geom) As length
|
||||
FROM phase_1_trace
|
||||
-- ce tri est le plus important
|
||||
ORDER BY secteur_id ASC, ordre ASC
|
||||
) AS t
|
||||
CROSS JOIN generate_series(0,10000) AS n
|
||||
WHERE n*1000.00/length < 1
|
||||
ORDER BY t.secteur_id ASC, t.ordre ASC ;
|
||||
|
||||
-- mise à jour des attributs
|
||||
UPDATE phase_1_trace_troncons
|
||||
SET
|
||||
longueur =
|
||||
(CASE
|
||||
WHEN TRUNC( ST_Length(the_geom)::numeric , 0) = 999 THEN 1000
|
||||
ELSE TRUNC( ST_Length(the_geom)::numeric , 0)
|
||||
END),
|
||||
km = uid -- km redadeg
|
||||
;
|
||||
|
|
@ -1,104 +0,0 @@
|
|||
/*
|
||||
==========================================================================
|
||||
|
||||
phase 2 : préparation des données
|
||||
|
||||
==========================================================================
|
||||
*/
|
||||
|
||||
-- dans la base redadeg on a chargé des données provenant de umap
|
||||
-- ces données sont en 3857. On va les passer en 2154 (Lambert 93).
|
||||
|
||||
|
||||
|
||||
|
||||
-- ici on fait une grosse requête qui va recaler les PK secteurs sur les nœuds routables
|
||||
-- ça insère les points de secteurs dans la table en 2154
|
||||
|
||||
TRUNCATE TABLE phase_2_pk_secteur ;
|
||||
|
||||
-- on fait une table de base qui contient les relations entre le point à recaler et les poins de référence
|
||||
-- on limite à un buffer de 25
|
||||
WITH candidates AS
|
||||
(
|
||||
SELECT
|
||||
pk_org.id AS pk_id,
|
||||
pk_org.name AS name,
|
||||
pk_org.secteur_id AS secteur_id,
|
||||
node.id AS node_id,
|
||||
ST_Distance(pk_org.the_geom, ST_ClosestPoint(node.the_geom, pk_org.the_geom)) AS distance,
|
||||
ST_Snap(
|
||||
pk_org.the_geom, -- le point d'origine à recaler
|
||||
ST_ClosestPoint(node.the_geom, pk_org.the_geom), -- le point le plus près dans la couche de nœuds
|
||||
ST_Distance(pk_org.the_geom, ST_ClosestPoint(node.the_geom, pk_org.the_geom))* 1.01 -- dans la distance de ce plus proche point
|
||||
) AS the_geom
|
||||
FROM
|
||||
(SELECT id::integer, name, secteur_id, ST_Transform(the_geom,2154) AS the_geom FROM phase_2_pk_secteur_3857) AS pk_org,
|
||||
(SELECT id, the_geom FROM osm_roads_pgr_vertices_pgr) AS node
|
||||
WHERE
|
||||
ST_INTERSECTS(node.the_geom, ST_BUFFER(ST_Transform(pk_org.the_geom,2154) ,25) )
|
||||
ORDER BY pk_org.id, ST_Distance(pk_org.the_geom, ST_ClosestPoint(node.the_geom, pk_org.the_geom))
|
||||
)
|
||||
-- à partir de cette table on va faire une jointure entre les PK org et les nœuds ramenés par la sous-requête
|
||||
INSERT INTO phase_2_pk_secteur
|
||||
SELECT
|
||||
a.pk_id AS id,
|
||||
a.name,
|
||||
b.node_id AS pgr_node_id,
|
||||
a.secteur_id::integer,
|
||||
b.the_geom
|
||||
FROM candidates a JOIN
|
||||
(
|
||||
-- on fait une table qui ordonne les points d'accroche
|
||||
SELECT
|
||||
pk_id, node_id,
|
||||
-- le rang va permettre de donner le rang de chaque rapprochement et d'en faire un critère
|
||||
row_number() over (partition by pk_id order by min(distance)) AS rang,
|
||||
min(distance) AS min_distance,
|
||||
the_geom
|
||||
FROM candidates
|
||||
GROUP BY pk_id, secteur_id, node_id, the_geom
|
||||
) b ON a.pk_id = b.pk_id
|
||||
WHERE b.rang = 1
|
||||
GROUP BY a.pk_id, a.name, a.secteur_id, b.node_id, b.the_geom
|
||||
ORDER BY a.pk_id ;
|
||||
|
||||
|
||||
|
||||
-- on recale également les points de nettoyage sur le tracé
|
||||
TRUNCATE TABLE phase_2_point_nettoyage ;
|
||||
|
||||
WITH candidates AS
|
||||
(
|
||||
SELECT
|
||||
pt_org.ogc_fid AS pt_id,
|
||||
edge.id AS edge_id,
|
||||
ST_Distance(pt_org.the_geom, ST_ClosestPoint(edge.the_geom, pt_org.the_geom)) AS distance,
|
||||
ST_Snap(
|
||||
pt_org.the_geom, -- le point d'origine à recaler
|
||||
ST_ClosestPoint(edge.the_geom, pt_org.the_geom), -- le point le plus près dans la couche de nœuds
|
||||
ST_Distance(pt_org.the_geom, ST_ClosestPoint(edge.the_geom, pt_org.the_geom))* 1.01 -- dans la distance de ce plus proche point
|
||||
) AS the_geom
|
||||
FROM
|
||||
(SELECT ogc_fid::integer, ST_Transform(the_geom,2154) AS the_geom FROM phase_2_point_nettoyage_3857) AS pt_org,
|
||||
(SELECT id, the_geom FROM osm_roads_pgr) AS edge
|
||||
WHERE
|
||||
ST_INTERSECTS(edge.the_geom, ST_BUFFER(ST_Transform(pt_org.the_geom,2154) ,2) )
|
||||
ORDER BY pt_org.ogc_fid, ST_Distance(pt_org.the_geom, ST_ClosestPoint(edge.the_geom, pt_org.the_geom))
|
||||
)
|
||||
INSERT INTO phase_2_point_nettoyage
|
||||
SELECT
|
||||
nextval('phase_2_point_nettoyage_id_seq'::regclass),
|
||||
pt_id,
|
||||
edge_id,
|
||||
distance,
|
||||
the_geom
|
||||
FROM candidates ;
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
||||
|
|
@ -1,79 +0,0 @@
|
|||
/*
|
||||
==========================================================================
|
||||
|
||||
phase 2 : création de différentes données à partir du tracé routé
|
||||
|
||||
==========================================================================
|
||||
*/
|
||||
|
||||
-- on prend le tracé routé et on fait une version simple
|
||||
-- 1 ligne par secteur
|
||||
TRUNCATE TABLE phase_2_trace_secteur ;
|
||||
WITH trace_ordered AS (
|
||||
SELECT secteur_id, (ST_Dump(the_geom)).geom AS the_geom
|
||||
FROM phase_2_trace_pgr
|
||||
--WHERE secteur_id = 8
|
||||
ORDER BY secteur_id, path_seq
|
||||
)
|
||||
INSERT INTO phase_2_trace_secteur
|
||||
SELECT
|
||||
secteur_id, '', '', 0, 0,
|
||||
ST_COLLECT(the_geom)
|
||||
--ST_UNION(the_geom)
|
||||
FROM trace_ordered
|
||||
GROUP BY secteur_id
|
||||
ORDER BY secteur_id ;
|
||||
|
||||
-- mise à jour des attributs
|
||||
UPDATE phase_2_trace_secteur a
|
||||
SET
|
||||
nom_fr = b.nom_fr,
|
||||
nom_br = b.nom_br,
|
||||
longueur = TRUNC( ST_Length(the_geom)::numeric , 0),
|
||||
longueur_km = TRUNC( ST_Length(the_geom)::numeric / 1000 , 1)
|
||||
FROM secteur b WHERE a.secteur_id = b.id ;
|
||||
|
||||
|
||||
TRUNCATE phase_2_trace_troncons ;
|
||||
INSERT INTO phase_2_trace_troncons
|
||||
SELECT
|
||||
row_number() over() as uid,
|
||||
-- infos redadeg
|
||||
NULL AS secteur_id,
|
||||
NULL AS ordre,
|
||||
NULL AS km,
|
||||
NULL AS km_reel,
|
||||
NULL AS longueur,
|
||||
-- infos OSM
|
||||
t.osm_id, t.highway, t.type, t.oneway, t.ref, t.name_fr, t.name_br,
|
||||
ST_LineSubstring(the_geom, 1000.00*n/length,
|
||||
CASE
|
||||
WHEN 1000.00*(n+1) < length THEN 1000.00*(n+1)/length
|
||||
ELSE 1
|
||||
END) AS the_geom
|
||||
FROM
|
||||
(SELECT
|
||||
id,
|
||||
osm_id, highway, "type", oneway, ref, name_fr, name_br,
|
||||
ST_LineMerge(the_geom)::geometry(LineString,2154) AS the_geom,
|
||||
ST_Length(the_geom) As length
|
||||
FROM phase_2_trace_pgr
|
||||
-- ce tri est le plus important
|
||||
ORDER BY id ASC
|
||||
) AS t
|
||||
CROSS JOIN generate_series(0,10000) AS n
|
||||
WHERE n*1000.00/length < 1
|
||||
ORDER BY t.id ;
|
||||
|
||||
-- mise à jour des attributs
|
||||
UPDATE phase_2_trace_troncons
|
||||
SET
|
||||
longueur =
|
||||
(CASE
|
||||
WHEN TRUNC( ST_Length(the_geom)::numeric , 0) = 999 THEN 1000
|
||||
ELSE TRUNC( ST_Length(the_geom)::numeric , 0)
|
||||
END),
|
||||
km = uid -- km redadeg
|
||||
;
|
||||
|
||||
|
|
@ -1,69 +0,0 @@
|
|||
/*
|
||||
==========================================================================
|
||||
|
||||
phase 2 : création de différentes données à partir du tracé routé
|
||||
|
||||
==========================================================================
|
||||
*/
|
||||
|
||||
-- on prend le tracé routé et on fait une version simple
|
||||
-- 1 ligne par secteur
|
||||
TRUNCATE TABLE phase_2_trace_secteur ;
|
||||
WITH trace_ordered AS (
|
||||
SELECT secteur_id, the_geom
|
||||
FROM phase_2_trace_pgr
|
||||
ORDER BY secteur_id, path_seq
|
||||
)
|
||||
INSERT INTO phase_2_trace_secteur
|
||||
SELECT
|
||||
secteur_id, '', '', 0, 0,
|
||||
ST_CollectionExtract(ST_UNION(the_geom),2) AS the_geom
|
||||
FROM trace_ordered
|
||||
GROUP BY secteur_id
|
||||
ORDER BY secteur_id ;
|
||||
|
||||
-- mise à jour des attributs
|
||||
UPDATE phase_2_trace_secteur a
|
||||
SET
|
||||
nom_fr = b.nom_fr,
|
||||
nom_br = b.nom_br,
|
||||
longueur = TRUNC( ST_Length(the_geom)::numeric , 0),
|
||||
longueur_km = TRUNC( ST_Length(the_geom)::numeric / 1000 , 1)
|
||||
FROM secteur b WHERE a.secteur_id = b.id ;
|
||||
|
||||
|
||||
/*
|
||||
TRUNCATE phase_2_trace_troncons ;
|
||||
INSERT INTO phase_2_trace_troncons
|
||||
SELECT
|
||||
row_number() over() as uid,
|
||||
-- infos redadeg
|
||||
NULL AS secteur_id,
|
||||
NULL AS km,
|
||||
NULL AS km_reel,
|
||||
NULL AS longueur,
|
||||
-- infos OSM
|
||||
--t.osm_id, t.highway, t.type, t.oneway, t.ref, t.name_fr, t.name_br,
|
||||
ST_LineSubstring(the_geom, 1000.00*n/length,
|
||||
CASE
|
||||
WHEN 1000.00*(n+1) < length THEN 1000.00*(n+1)/length
|
||||
ELSE 1
|
||||
END) AS the_geom
|
||||
FROM
|
||||
(
|
||||
SELECT
|
||||
secteur_id,
|
||||
ST_LineMerge(the_geom)::geometry(MultiLineString,2154) AS the_geom,
|
||||
ST_Length(the_geom) AS length,
|
||||
ST_GeometryType(ST_LineMerge(the_geom)::geometry(MultiLineString,2154)) AS geom_type
|
||||
FROM phase_2_trace_secteur
|
||||
--WHERE secteur_id = 8
|
||||
--GROUP BY secteur_id
|
||||
-- ce tri est le plus important
|
||||
ORDER BY secteur_id ASC
|
||||
) AS t
|
||||
CROSS JOIN generate_series(0,10000) AS n
|
||||
WHERE n*1000.00/length < 1
|
||||
ORDER BY t.secteur_id ;
|
||||
*/
|
||||
|
|
@ -1,271 +0,0 @@
|
|||
#!/bin/bash
|
||||
|
||||
set -e
|
||||
set -u
|
||||
|
||||
# argument 1 = millesime redadeg
|
||||
millesime=$1
|
||||
|
||||
PSQL=/usr/bin/psql
|
||||
DB_HOST=localhost
|
||||
DB_PORT=5432
|
||||
DB_NAME=redadeg_$millesime
|
||||
DB_USER=redadeg
|
||||
DB_PASSWD=redadeg
|
||||
|
||||
rep_scripts='/data/projets/ar_redadeg/scripts/'
|
||||
echo "rep_scripts = $rep_scripts"
|
||||
# variables liées au millésimes
|
||||
echo "millesime de travail = $1"
|
||||
rep_data=../data/$millesime
|
||||
echo "rep_data = $rep_data"
|
||||
echo "base de données = $DB_NAME"
|
||||
echo ""
|
||||
|
||||
|
||||
# ++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++
|
||||
# on récupère les couches geojson depuis umap
|
||||
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " Récupération des fichiers geojson depuis umap"
|
||||
|
||||
# les couches PK
|
||||
# PK début - fin de secteur
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/817220/ > $rep_data/phase_2_umap_pk_secteur.geojson
|
||||
# PK techniques
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/817221/ > $rep_data/phase_2_umap_pk_technique.geojson
|
||||
# PK manuels
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/817222/ > $rep_data/phase_2_umap_pk_manuel.geojson
|
||||
# couche de points de nettoyage
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/861810/ > $rep_data/phase_2_umap_point_nettoyage.geojson
|
||||
|
||||
echo " fait"
|
||||
echo ""
|
||||
|
||||
# ++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++
|
||||
# on les charge dans postgis
|
||||
# après avoir supprimé les tables
|
||||
|
||||
# note : les coordonnées sont en 3857 mais la déclaration de la table = 4326
|
||||
|
||||
echo " chargement des fichiers dans la BD"
|
||||
echo ""
|
||||
|
||||
echo "phase_2_pk_secteur_3857"
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $DB_HOST -p $DB_PORT -U $DB_USER -d $DB_NAME -c "DROP TABLE IF EXISTS phase_2_pk_secteur_3857 CASCADE;"
|
||||
ogr2ogr -f "PostgreSQL" PG:"host=$DB_HOST user=$DB_USER password=$DB_PASSWD dbname=$DB_NAME" $rep_data/phase_2_umap_pk_secteur.geojson -nln phase_2_pk_secteur_3857 -lco GEOMETRY_NAME=the_geom -explodecollections -overwrite
|
||||
|
||||
echo "phase_2_point_nettoyage_3857"
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $DB_HOST -p $DB_PORT -U $DB_USER -d $DB_NAME -c "DROP TABLE IF EXISTS phase_2_point_nettoyage_3857 CASCADE;"
|
||||
ogr2ogr -f "PostgreSQL" PG:"host=$DB_HOST user=$DB_USER password=$DB_PASSWD dbname=$DB_NAME" $rep_data/phase_2_umap_point_nettoyage.geojson -nln phase_2_point_nettoyage_3857 -lco GEOMETRY_NAME=the_geom -explodecollections -overwrite
|
||||
|
||||
echo " fait"
|
||||
echo ""
|
||||
|
||||
# on crée les tables en 3948
|
||||
# et bien d'autres choses :
|
||||
# - recalage des PK secteurs sur un nœud du réseau routable
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " Application des traitements SQL 2.1"
|
||||
echo ""
|
||||
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $DB_HOST -p $DB_PORT -U $DB_USER -d $DB_NAME < traitements_phase_2.1.sql
|
||||
|
||||
echo " fait"
|
||||
echo ""
|
||||
|
||||
|
||||
|
||||
# ++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++
|
||||
# ici on va calculer un itinéraire pour chaque secteur
|
||||
# en utilisant les PK de début (ou fin) de chaque secteur
|
||||
|
||||
# https://www.manniwood.com/postgresql_and_bash_stuff/index.html
|
||||
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " Calcul des itinéraires (pgrouting)"
|
||||
echo ""
|
||||
|
||||
# on commence par vider la table qui contiendra les calculs d'itinéraires
|
||||
echo "vidage de la couche de routage"
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $DB_HOST -p $DB_PORT -U $DB_USER -d $DB_NAME -c "TRUNCATE TABLE phase_2_trace_pgr ;"
|
||||
echo " fait"
|
||||
|
||||
# ensuite : on supprime les tronçons ciblés par la couche de points de nettoyage
|
||||
# AVANT de calculer les itinéraires
|
||||
echo "nettoyage de la couche de routage par les points ciblés"
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $DB_HOST -p $DB_PORT -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 ""
|
||||
|
||||
|
||||
# on fait la requête qui va donner une liste de PK de secteurs
|
||||
# et on calcule un itinéraire entre le PK de début et le PK suivant
|
||||
|
||||
# on va utiliser un compteur pour pouvoir sauter un sous-secteur à un autre
|
||||
counter=1
|
||||
# autre variables de contrôle
|
||||
longueur_totale=0
|
||||
longueur_inseree=0
|
||||
|
||||
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -X -h $DB_HOST -p $DB_PORT -U $DB_USER -d $DB_NAME \
|
||||
-c "SELECT pk.id, s.id AS secteur_id, replace(s.nom_fr,' ','') AS nom_fr, replace(s.nom_br,' ','') AS nom_br, pk.pgr_node_id, replace(pk.name,' ','_') AS name
|
||||
FROM phase_2_pk_secteur pk JOIN secteur s ON pk.secteur_id = s.id
|
||||
ORDER BY pk.id ;" \
|
||||
--single-transaction \
|
||||
--set AUTOCOMMIT=off \
|
||||
--set ON_ERROR_STOP=on \
|
||||
--no-align \
|
||||
-t \
|
||||
--field-separator ' ' \
|
||||
--quiet | while read -a Record ; do
|
||||
|
||||
# ici commence la boucle sur les PK de secteurs
|
||||
echo "----------------------------"
|
||||
|
||||
#IFS="|" pour forcer un délimiteur mais ne fonctionne pas : les espaces sont compris comme des séparateurs
|
||||
# alors la requête supprime les espaces. TODO
|
||||
|
||||
# le premier PK = PK de début
|
||||
pk_id=${Record[0]}
|
||||
secteur_id=${Record[1]}
|
||||
secteur_nom_fr="${Record[2]}"
|
||||
secteur_nom_br="${Record[3]}"
|
||||
pk_id_start=${Record[4]}
|
||||
troncon_name=${Record[5]}
|
||||
|
||||
echo " $secteur_id | $secteur_nom_fr / $secteur_nom_br"
|
||||
echo " tronçon : $troncon_name"
|
||||
echo " PK ID = $pk_id"
|
||||
echo " start node = $pk_id_start"
|
||||
|
||||
# on fait une requête pour récupérer l'id du nœud de routage de fin
|
||||
# ce nœud = le PK de début du secteur suivant
|
||||
read pk_id_end <<< $(PGPASSWORD=$DB_PASSWD $PSQL -h $DB_HOST -p $DB_PORT -U $DB_USER -d $DB_NAME --no-align -t --quiet \
|
||||
-c "SELECT pgr_node_id FROM phase_2_pk_secteur ORDER BY id OFFSET $counter LIMIT 1 ;" )
|
||||
|
||||
echo " end node = $pk_id_end"
|
||||
|
||||
|
||||
# on teste si on récupère qqch sinon ça veurt dire qu'on a pas de nœud de fin donc impossible de calculer un itinéraire
|
||||
if [[ -n "$pk_id_end" ]];
|
||||
then
|
||||
echo " calcul de l'itinéraire"
|
||||
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $DB_HOST -p $DB_PORT -U $DB_USER -d $DB_NAME -c \
|
||||
"INSERT INTO phase_2_trace_pgr
|
||||
SELECT
|
||||
$secteur_id AS secteur_id,
|
||||
-- info de routage
|
||||
a.path_seq,
|
||||
a.node,
|
||||
a.cost,
|
||||
a.agg_cost,
|
||||
-- infos OSM
|
||||
b.osm_id,
|
||||
b.highway,
|
||||
b.\"type\",
|
||||
b.oneway,
|
||||
b.ref,
|
||||
CASE
|
||||
WHEN b.name_fr IS NULL AND b.ref IS NOT NULL THEN b.ref
|
||||
ELSE b.name_fr
|
||||
END AS name_fr,
|
||||
CASE
|
||||
WHEN b.name_br IS NULL AND b.name_fr IS NULL AND b.ref IS NOT NULL THEN b.ref
|
||||
WHEN b.name_br IS NULL AND b.name_fr IS NOT NULL THEN '# da dreiñ e brezhoneg #'
|
||||
ELSE b.name_br
|
||||
END AS name_br,
|
||||
b.the_geom
|
||||
FROM pgr_dijkstra(
|
||||
'SELECT id, source, target, cost, reverse_cost FROM osm_roads_pgr', $pk_id_start, $pk_id_end) as a
|
||||
JOIN osm_roads_pgr b ON a.edge = b.id ;" >> /dev/null
|
||||
|
||||
# on fait une requête pour voir la longueur insérée
|
||||
# en fait : la longueur totale - la longueur totale lors du précédent calcul
|
||||
read longueur_base <<< $(PGPASSWORD=$DB_PASSWD $PSQL -h $DB_HOST -p $DB_PORT -U $DB_USER -d $DB_NAME --no-align -t --quiet \
|
||||
-c "SELECT trunc(SUM(ST_Length(the_geom))/1000) as longueur_totale FROM phase_2_trace_pgr ;" )
|
||||
longueur_inseree=$(($longueur_base-$longueur_totale))
|
||||
longueur_totale=$longueur_base
|
||||
|
||||
# une alerte si 0 km insérés
|
||||
if [ $longueur_inseree -eq 0 ] ;
|
||||
then
|
||||
echo ""
|
||||
echo " E R R E U R !!!!!!!!"
|
||||
echo ""
|
||||
else
|
||||
echo " fait : $longueur_inseree km (total = $longueur_totale km)"
|
||||
fi
|
||||
|
||||
else
|
||||
echo ""
|
||||
echo " E R R E U R !!!!!!!!"
|
||||
echo " impossible de calculer un itinéraire pour ce secteur"
|
||||
echo ""
|
||||
fi
|
||||
|
||||
|
||||
# fin de la boucle
|
||||
# on incrémente le compteur
|
||||
((counter++))
|
||||
echo ""
|
||||
|
||||
done
|
||||
|
||||
echo " Calcul des itinéraires terminé"
|
||||
echo ""
|
||||
|
||||
|
||||
# ++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++
|
||||
# on applique maintenant des requêtes SQL de création des données dérivées des données de routage
|
||||
|
||||
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " Application des traitements SQL 2.2"
|
||||
echo ""
|
||||
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $DB_HOST -p $DB_PORT -U $DB_USER -d $DB_NAME < traitements_phase_2.2.sql
|
||||
|
||||
|
||||
|
||||
|
||||
# ++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++
|
||||
# et on exporte en geojson pour umap
|
||||
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " Exports et upload vers le serveur de diffusion"
|
||||
echo ""
|
||||
|
||||
echo " exports geojson"
|
||||
echo ""
|
||||
|
||||
rm -f $rep_data/phase_2_pk_secteur.geojson
|
||||
ogr2ogr -f "GeoJSON" $rep_data/phase_2_pk_secteur.geojson PG:"host=$DB_HOST user=$DB_USER password=$DB_PASSWD dbname=$DB_NAME" phase_2_pk_secteur_4326
|
||||
rm -f $rep_data/phase_2_trace_pgr.geojson
|
||||
ogr2ogr -f "GeoJSON" $rep_data/phase_2_trace_pgr.geojson PG:"host=$DB_HOST user=$DB_USER password=$DB_PASSWD dbname=$DB_NAME" phase_2_trace_pgr_4326
|
||||
rm -f $rep_data/phase_2_trace_secteur.geojson
|
||||
ogr2ogr -f "GeoJSON" $rep_data/phase_2_trace_secteur.geojson PG:"host=$DB_HOST user=$DB_USER password=$DB_PASSWD dbname=$DB_NAME" phase_2_trace_secteur_4326
|
||||
# les fichiers sont ensuite tout de suite visible dans umap
|
||||
|
||||
|
||||
# exports supplémentaires
|
||||
echo " exports supplémentaires"
|
||||
echo ""
|
||||
|
||||
rm -f $rep_data/phase_2_tdb.xlsx
|
||||
ogr2ogr -f "XLSX" $rep_data/phase_2_tdb.xlsx PG:"host=$DB_HOST user=$DB_USER password=$DB_PASSWD dbname=$DB_NAME" phase_2_tdb
|
||||
rm -f $rep_data/phase_2_tdb.csv
|
||||
ogr2ogr -f "CSV" $rep_data/phase_2_tdb.csv PG:"host=$DB_HOST user=$DB_USER password=$DB_PASSWD dbname=$DB_NAME" phase_2_tdb
|
||||
|
||||
echo " fait"
|
||||
echo ""
|
||||
|
||||
|
||||
echo ""
|
||||
echo ""
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " F I N traitements phase 2"
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo ""
|
|
@ -1,84 +0,0 @@
|
|||
#!/bin/bash
|
||||
|
||||
set -e
|
||||
set -u
|
||||
|
||||
# argument 1 = millesime redadeg
|
||||
millesime=$1
|
||||
|
||||
# linux
|
||||
#PSQL=/usr/bin/psql
|
||||
# mac via brew
|
||||
PSQL=/usr/local/bin/psql
|
||||
|
||||
DB_HOST=localhost
|
||||
DB_PORT=55432
|
||||
DB_NAME=redadeg_$millesime
|
||||
DB_USER=redadeg
|
||||
DB_PASSWD=redadeg
|
||||
|
||||
# server bed110
|
||||
#rep_scripts='/data/projets/ar_redadeg/scripts/'
|
||||
# mac
|
||||
rep_scripts='/Volumes/ker/mael/projets/osm_bzh/github/ar_redadeg/scripts'
|
||||
|
||||
echo "rep_scripts = $rep_scripts"
|
||||
# variables liées au millésimes
|
||||
echo "millesime de travail = $1"
|
||||
rep_data=../data/$millesime
|
||||
echo "rep_data = $rep_data"
|
||||
echo "base de données = $DB_NAME sur $DB_HOST:$DB_PORT"
|
||||
echo ""
|
||||
|
||||
exit 1
|
||||
|
||||
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " Création des données phase 3"
|
||||
echo ""
|
||||
|
||||
# création des PK auto par découpage des tronçons de la phase 2
|
||||
/Library/FME/2021.0/fme traitements_phase_3_decoupage.fmw
|
||||
|
||||
# en sortie on obtient :
|
||||
# phase_3_pk_auto = couche de points
|
||||
# phase_3_pk_sens_verif = couche de ligne direct PK à PK
|
||||
|
||||
|
||||
|
||||
# ++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++
|
||||
# et on exporte en geojson pour umap
|
||||
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " Exports et upload vers le serveur de diffusion"
|
||||
echo ""
|
||||
|
||||
echo " exports geojson"
|
||||
echo ""
|
||||
|
||||
rm $rep_data/phase_3_pk_auto.geojson
|
||||
ogr2ogr -f "GeoJSON" $rep_data/phase_3_pk_auto.geojson PG:"host=$DB_HOST user=$DB_USER password=$DB_PASSWD dbname=$DB_NAME" phase_3_pk_auto_4326
|
||||
rm $rep_data/phase_3_pk_sens_verif.geojson
|
||||
ogr2ogr -f "GeoJSON" $rep_data/phase_3_pk_sens_verif.geojson PG:"host=$DB_HOST user=$DB_USER password=$DB_PASSWD dbname=$DB_NAME" phase_3_pk_sens_verif_4326
|
||||
rm $rep_data/phase_3_trace_troncons.geojson
|
||||
ogr2ogr -f "GeoJSON" $rep_data/phase_3_trace_troncons.geojson PG:"host=$DB_HOST user=$DB_USER password=$DB_PASSWD dbname=$DB_NAME" phase_3_trace_troncons_4326
|
||||
rm $rep_data/phase_3_trace_secteurs.geojson
|
||||
ogr2ogr -f "GeoJSON" $rep_data/phase_3_trace_secteurs.geojson PG:"host=$DB_HOST user=$DB_USER password=$DB_PASSWD dbname=$DB_NAME" phase_3_trace_secteurs_4326
|
||||
|
||||
echo " fait"
|
||||
echo ""
|
||||
echo " upload"
|
||||
echo ""
|
||||
|
||||
# upload
|
||||
rsync -av -z $rep_data/phase_3_*.geojson bed100.bedniverel.bzh:/data/projets/ar_redadeg/data/$millesime/
|
||||
|
||||
echo " fait"
|
||||
echo ""
|
||||
|
||||
echo ""
|
||||
echo ""
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " F I N traitements phase 3"
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo ""
|
File diff suppressed because it is too large
Load diff
File diff suppressed because it is too large
Load diff
File diff suppressed because it is too large
Load diff
|
@ -1,76 +0,0 @@
|
|||
#!/bin/bash
|
||||
|
||||
# ce traitement consiste à exporter les données tracé et PK auto de la phase 4 pour alimenter autant de cartes Umap que de secteurs.
|
||||
# ces cartes umap servent en phase 5 à modifier le placement des PK
|
||||
# phase 5 = gestion manuelle des PK
|
||||
|
||||
|
||||
set -e
|
||||
set -u
|
||||
|
||||
PSQL=/usr/bin/psql
|
||||
DB_HOST=192.168.56.131
|
||||
DB_NAME=redadeg
|
||||
DB_USER=redadeg
|
||||
|
||||
|
||||
|
||||
#cd /data/www/vhosts/ar-redadeg_openstreetmap_bzh/htdocs/scripts/
|
||||
|
||||
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " Création des données phase 4"
|
||||
echo ""
|
||||
echo " exports geojson par secteurs"
|
||||
echo ""
|
||||
|
||||
|
||||
ogr2ogr -f "GeoJSON" data/phase_4_pk_secteur_01.geojson PG:"host=$DB_HOST user=redadeg password=redadeg dbname=redadeg" phase_4_pk_auto_4326 -where "secteur_id = 10"
|
||||
|
||||
|
||||
ogr2ogr -f "GeoJSON" data/phase_4_pk_secteur_02.geojson PG:"host=$DB_HOST user=redadeg password=redadeg dbname=redadeg" phase_4_pk_auto_4326 -where "secteur_id = 20"
|
||||
|
||||
|
||||
ogr2ogr -f "GeoJSON" data/phase_4_pk_secteur_03.geojson PG:"host=$DB_HOST user=redadeg password=redadeg dbname=redadeg" phase_4_pk_auto_4326 -where "secteur_id = 30"
|
||||
|
||||
|
||||
ogr2ogr -f "GeoJSON" data/phase_4_pk_secteur_04.geojson PG:"host=$DB_HOST user=redadeg password=redadeg dbname=redadeg" phase_4_pk_auto_4326 -where "secteur_id = 40"
|
||||
|
||||
|
||||
ogr2ogr -f "GeoJSON" data/phase_4_pk_secteur_05.geojson PG:"host=$DB_HOST user=redadeg password=redadeg dbname=redadeg" phase_4_pk_auto_4326 -where "secteur_id = 50"
|
||||
|
||||
|
||||
ogr2ogr -f "GeoJSON" data/phase_4_pk_secteur_06.geojson PG:"host=$DB_HOST user=redadeg password=redadeg dbname=redadeg" phase_4_pk_auto_4326 -where "secteur_id >= 60 and secteur_id < 70"
|
||||
|
||||
|
||||
ogr2ogr -f "GeoJSON" data/phase_4_pk_secteur_07.geojson PG:"host=$DB_HOST user=redadeg password=redadeg dbname=redadeg" phase_4_pk_auto_4326 -where "secteur_id >= 70 and secteur_id < 80"
|
||||
|
||||
|
||||
ogr2ogr -f "GeoJSON" data/phase_4_pk_secteur_08.geojson PG:"host=$DB_HOST user=redadeg password=redadeg dbname=redadeg" phase_4_pk_auto_4326 -where "secteur_id >= 80 and secteur_id < 90"
|
||||
|
||||
|
||||
ogr2ogr -f "GeoJSON" data/phase_4_pk_secteur_09.geojson PG:"host=$DB_HOST user=redadeg password=redadeg dbname=redadeg" phase_4_pk_auto_4326 -where "secteur_id >= 90 and secteur_id < 100"
|
||||
|
||||
|
||||
ogr2ogr -f "GeoJSON" data/phase_4_pk_secteur_10.geojson PG:"host=$DB_HOST user=redadeg password=redadeg dbname=redadeg" phase_4_pk_auto_4326 -where "secteur_id >= 100 and secteur_id < 110"
|
||||
|
||||
|
||||
echo " fait"
|
||||
echo ""
|
||||
|
||||
echo " pousse vers serveur"
|
||||
echo ""
|
||||
|
||||
rsync -av -z data/phase_4_*.geojson breizhpovh2:/data/www/vhosts/ar-redadeg_openstreetmap_bzh/htdocs/scripts/data/
|
||||
|
||||
echo ""
|
||||
echo " fait"
|
||||
echo ""
|
||||
|
||||
|
||||
echo ""
|
||||
echo ""
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " F I N"
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo ""
|
|
@ -1,296 +0,0 @@
|
|||
#!/bin/bash
|
||||
|
||||
# ce traitement consiste à charger les données des 10 cartes umap
|
||||
# à les contrôler par rapport aux données de référence
|
||||
# à les agréger
|
||||
# puis les exporter pour merour
|
||||
|
||||
|
||||
set -e
|
||||
set -u
|
||||
|
||||
#PSQL=/usr/bin/psql
|
||||
PSQL=psql
|
||||
DB_HOST=breizhpolenovo
|
||||
DB_NAME=redadeg
|
||||
DB_USER=redadeg
|
||||
DB_PASS=redadeg
|
||||
|
||||
|
||||
#cd /data/www/vhosts/ar-redadeg_openstreetmap_bzh/htdocs/scripts/
|
||||
|
||||
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " Chargement des données des cartes umap"
|
||||
echo ""
|
||||
echo ""
|
||||
|
||||
|
||||
# OK !
|
||||
#dernierFichierCmd="ls -l1dt phase_5_pk_secteur_"$secteur"_* | head -1"
|
||||
#eval $dernierFichierCmd
|
||||
|
||||
|
||||
# on procède secteur par secteur
|
||||
# on récupère les données umap et on les charge dans la même couche
|
||||
|
||||
# on commence donc par vider la couche cible
|
||||
# géré avec l'option -overwrite sur le secteur 1 -> pb : on a des lignes dans la couche de points…
|
||||
# on commence par vider la table qui contiendra les calculs d'itinéraires
|
||||
|
||||
echo " vidage de la couche de routage"
|
||||
$PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME -c "TRUNCATE TABLE phase_5_pk_umap_4326 ;"
|
||||
echo " fait"
|
||||
|
||||
echo ""
|
||||
echo " import des données umap"
|
||||
echo ""
|
||||
|
||||
echo " secteur 1"
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/1027042/ > data/phase_5_pk_umap_tmp.geojson
|
||||
# chargement initial
|
||||
ogr2ogr -f "PostgreSQL" PG:"host=$DB_HOST user=$DB_USER password=$DB_PASS dbname=$DB_NAME" \
|
||||
data/phase_5_pk_umap_tmp.geojson -nln phase_5_pk_umap_4326 -explodecollections -append
|
||||
|
||||
|
||||
echo " secteur 2"
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/1027081/ > data/phase_5_pk_umap_tmp.geojson
|
||||
# on rajoute à la couche
|
||||
ogr2ogr -f "PostgreSQL" PG:"host=$DB_HOST user=$DB_USER password=$DB_PASS dbname=$DB_NAME" \
|
||||
data/phase_5_pk_umap_tmp.geojson -nln phase_5_pk_umap_4326 -explodecollections -append
|
||||
|
||||
|
||||
echo " secteur 3"
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/1027101/ > data/phase_5_pk_umap_tmp.geojson
|
||||
# on rajoute à la couche
|
||||
ogr2ogr -f "PostgreSQL" PG:"host=$DB_HOST user=$DB_USER password=$DB_PASS dbname=$DB_NAME" \
|
||||
data/phase_5_pk_umap_tmp.geojson -nln phase_5_pk_umap_4326 -explodecollections -append
|
||||
|
||||
|
||||
echo " secteur 4"
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/1027104/ > data/phase_5_pk_umap_tmp.geojson
|
||||
# on rajoute à la couche
|
||||
ogr2ogr -f "PostgreSQL" PG:"host=$DB_HOST user=$DB_USER password=$DB_PASS dbname=$DB_NAME" \
|
||||
data/phase_5_pk_umap_tmp.geojson -nln phase_5_pk_umap_4326 -explodecollections -append
|
||||
|
||||
|
||||
echo " secteur 5"
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/1027107/ > data/phase_5_pk_umap_tmp.geojson
|
||||
# on rajoute à la couche
|
||||
ogr2ogr -f "PostgreSQL" PG:"host=$DB_HOST user=$DB_USER password=$DB_PASS dbname=$DB_NAME" \
|
||||
data/phase_5_pk_umap_tmp.geojson -nln phase_5_pk_umap_4326 -explodecollections -append
|
||||
|
||||
|
||||
echo " secteur 6"
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/1027110/ > data/phase_5_pk_umap_tmp.geojson
|
||||
# on rajoute à la couche
|
||||
ogr2ogr -f "PostgreSQL" PG:"host=$DB_HOST user=$DB_USER password=$DB_PASS dbname=$DB_NAME" \
|
||||
data/phase_5_pk_umap_tmp.geojson -nln phase_5_pk_umap_4326 -explodecollections -append
|
||||
|
||||
|
||||
echo " secteur 7"
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/1027114/ > data/phase_5_pk_umap_tmp.geojson
|
||||
# on rajoute à la couche
|
||||
ogr2ogr -f "PostgreSQL" PG:"host=$DB_HOST user=$DB_USER password=$DB_PASS dbname=$DB_NAME" \
|
||||
data/phase_5_pk_umap_tmp.geojson -nln phase_5_pk_umap_4326 -explodecollections -append
|
||||
|
||||
|
||||
echo " secteur 8"
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/1027117/ > data/phase_5_pk_umap_tmp.geojson
|
||||
# on rajoute à la couche
|
||||
ogr2ogr -f "PostgreSQL" PG:"host=$DB_HOST user=$DB_USER password=$DB_PASS dbname=$DB_NAME" \
|
||||
data/phase_5_pk_umap_tmp.geojson -nln phase_5_pk_umap_4326 -explodecollections -append
|
||||
|
||||
|
||||
echo " secteur 9"
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/1027120/ > data/phase_5_pk_umap_tmp.geojson
|
||||
# on rajoute à la couche
|
||||
ogr2ogr -f "PostgreSQL" PG:"host=$DB_HOST user=$DB_USER password=$DB_PASS dbname=$DB_NAME" \
|
||||
data/phase_5_pk_umap_tmp.geojson -nln phase_5_pk_umap_4326 -explodecollections -append
|
||||
|
||||
|
||||
echo " secteur 10"
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/1027123/ > data/phase_5_pk_umap_tmp.geojson
|
||||
# on rajoute à la couche
|
||||
ogr2ogr -f "PostgreSQL" PG:"host=$DB_HOST user=$DB_USER password=$DB_PASS dbname=$DB_NAME" \
|
||||
data/phase_5_pk_umap_tmp.geojson -nln phase_5_pk_umap_4326 -explodecollections -append
|
||||
|
||||
|
||||
|
||||
# ensuite on supprime les enregistrement aberrants
|
||||
echo ""
|
||||
echo " suppression des données nulles"
|
||||
$PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME -c "DELETE FROM phase_5_pk_umap_4326 WHERE ST_geometrytype(the_geom) <> 'ST_Point' OR secteur_id IS NULL OR pk_id IS NULL ;"
|
||||
echo " fait"
|
||||
|
||||
|
||||
# et on charge la couche en 2154 pour pouvoir travailler
|
||||
echo ""
|
||||
echo " chargement de la couche de travail en 2154"
|
||||
$PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME \
|
||||
-c "TRUNCATE phase_5_pk_umap ;
|
||||
INSERT INTO phase_5_pk_umap
|
||||
SELECT pk_id, secteur_id, ST_Transform(the_geom,2154) AS the_geom
|
||||
FROM phase_5_pk_umap_4326
|
||||
ORDER BY pk_id ;"
|
||||
echo " fait"
|
||||
|
||||
|
||||
echo ""
|
||||
echo ""
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " Contrôle des données par secteur"
|
||||
echo ""
|
||||
|
||||
# on veut la liste des vrais secteurs : pas des secteurs de gestion
|
||||
# on instancie donc un tableau
|
||||
|
||||
declare -a secteursArray=()
|
||||
|
||||
secteursArray=(`$PSQL -h $DB_HOST -U $DB_USER $DB_NAME -t -X -A -c \
|
||||
"WITH a AS
|
||||
(
|
||||
SELECT substring(secteur_id::text,1, char_length(secteur_id::text)-1)::integer AS secteur_id
|
||||
FROM phase_5_pk_ref
|
||||
)
|
||||
SELECT DISTINCT(secteur_id) FROM a ORDER BY secteur_id ;"`)
|
||||
|
||||
#echo "secteursArray = " ${secteursArray[@]}
|
||||
|
||||
|
||||
# ++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++
|
||||
echo ""
|
||||
echo " 1 : nombre de PK par secteur"
|
||||
echo ""
|
||||
|
||||
for secteur in ${secteursArray[@]}
|
||||
do
|
||||
#echo " secteur $secteur"
|
||||
|
||||
# une requête qui compare le nb de PK entre la couche de référence et la couche umap
|
||||
sect_deb=$secteur"0" # 1 --> 10
|
||||
sect_fin=$((secteur+1))0
|
||||
#echo "$sect_deb -> $sect_fin"
|
||||
|
||||
$PSQL -X -A -t -h $DB_HOST -U $DB_USER $DB_NAME \
|
||||
-c "WITH ref AS (
|
||||
SELECT COUNT(pk_id) as ref FROM phase_5_pk_ref
|
||||
WHERE (secteur_id >= $sect_deb and secteur_id < $sect_fin)
|
||||
),
|
||||
umap AS (
|
||||
SELECT COUNT(pk_id) as umap FROM phase_5_pk_umap
|
||||
WHERE (secteur_id >= $sect_deb and secteur_id < $sect_fin)
|
||||
)
|
||||
SELECT
|
||||
*,
|
||||
CASE
|
||||
WHEN ref.ref < umap.umap THEN 'plus'
|
||||
WHEN ref.ref > umap.umap THEN 'moins'
|
||||
WHEN ref.ref = umap.umap THEN 'pareil'
|
||||
ELSE 'problème'
|
||||
END AS test
|
||||
FROM ref, umap" \
|
||||
--single-transaction \
|
||||
--set AUTOCOMMIT=off \
|
||||
--set ON_ERROR_STOP=on \
|
||||
--no-align \
|
||||
-t \
|
||||
--field-separator ' ' \
|
||||
--quiet | while read -a Record ; do
|
||||
|
||||
nbPKref=${Record[0]}
|
||||
nbPKumap=${Record[1]}
|
||||
test=${Record[2]}
|
||||
#test='moins'
|
||||
|
||||
# on teste
|
||||
if [[ $test == "pareil" ]];
|
||||
then echo " secteur $secteur ok : $nbPKref PK"
|
||||
elif [[ $test == "plus" ]];
|
||||
then echo " secteur $secteur >>>> problème : " $((nbPKumap - $nbPKref)) " PK en trop"
|
||||
elif [[ $test == "moins" ]];
|
||||
then echo " secteur $secteur >>>> problème : " $((nbPKref - $nbPKumap)) " PK en moins"
|
||||
fi
|
||||
|
||||
done
|
||||
|
||||
# fin de la boucle
|
||||
done
|
||||
|
||||
|
||||
# ++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++
|
||||
echo ""
|
||||
echo ""
|
||||
echo " 2 : si replacement : test de distance"
|
||||
echo ""
|
||||
|
||||
|
||||
# ici une requête PostGIS sortira les PK qui auront été trop déplacés
|
||||
|
||||
read nb_pk_deplaces <<< $( $PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME --no-align -t --quiet -c \
|
||||
"SELECT COUNT(*)
|
||||
FROM phase_5_pk_ref r FULL JOIN phase_5_pk_umap u ON r.pk_id = u.pk_id
|
||||
WHERE TRUNC(ST_Distance(r.the_geom, u.the_geom)::numeric,2) > 1 ;"
|
||||
)
|
||||
|
||||
echo " $nb_pk_deplaces PK déplacés manuellement"
|
||||
|
||||
|
||||
|
||||
|
||||
echo ""
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " Application des traitements SQL phase 5"
|
||||
echo ""
|
||||
|
||||
echo " Recalage des PK sur le filaire OSM"
|
||||
echo ""
|
||||
|
||||
/Library/FME/2018.1/fme traitements_phase_5_recalage.fmw
|
||||
|
||||
echo " fait"
|
||||
echo ""
|
||||
|
||||
|
||||
|
||||
|
||||
# ++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++
|
||||
# et on exporte en geojson pour umap et merour
|
||||
|
||||
echo ""
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " Exports"
|
||||
echo ""
|
||||
|
||||
echo " exports geojson"
|
||||
echo ""
|
||||
|
||||
# la couche agrégée des PK gérés dans umap
|
||||
rm data/phase_5_pk_umap.geojson
|
||||
ogr2ogr -f "GeoJSON" data/phase_5_pk_umap.geojson PG:"host=$DB_HOST user=redadeg password=redadeg dbname=redadeg" \
|
||||
-sql "SELECT pk_id, secteur_id, the_geom FROM phase_5_pk_umap_4326 ORDER BY pk_id"
|
||||
|
||||
# la nouvelle couche des PK recalés sur le tracé et avec les infos des voies OSM
|
||||
rm data/phase_5_pk.geojson
|
||||
ogr2ogr -f "GeoJSON" data/phase_5_pk.geojson PG:"host=$DB_HOST user=redadeg password=redadeg dbname=redadeg" \
|
||||
-sql "SELECT * FROM phase_5_pk ORDER BY pk_id"
|
||||
|
||||
echo " fait"
|
||||
echo ""
|
||||
|
||||
echo " pousse vers serveur"
|
||||
echo ""
|
||||
|
||||
rsync -av -z data/phase_5_pk_umap.geojson data/phase_5_pk.geojson data/phase_5_pk_hors_tolerance.geojson breizhpovh2:/data/www/vhosts/ar-redadeg_openstreetmap_bzh/htdocs/scripts/data/
|
||||
|
||||
echo ""
|
||||
echo " fait"
|
||||
echo ""
|
||||
|
||||
|
||||
echo ""
|
||||
echo ""
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " F I N"
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo ""
|
|
@ -1,37 +0,0 @@
|
|||
|
||||
|
||||
|
||||
-- on vide puis on remplit à nouveau la couche finale des PK
|
||||
TRUNCATE phase_5_pk ;
|
||||
|
||||
-- pour le moment avec les données de référence
|
||||
INSERT INTO phase_5_pk
|
||||
SELECT
|
||||
r.pk_id,
|
||||
ROUND(ST_X(ST_Transform(u.the_geom,2154))::numeric,1) as pk_x,
|
||||
ROUND(ST_Y(ST_Transform(u.the_geom,2154))::numeric,1) as pk_y,
|
||||
ST_X(u.the_geom) as pk_long,
|
||||
ST_Y(u.the_geom) as pk_lat,
|
||||
NULL as length_real,
|
||||
r.length_theorical,
|
||||
r.secteur_id,
|
||||
r.municipality_admincode,
|
||||
r.municipality_postcode,
|
||||
r.municipality_name_fr,
|
||||
r.municipality_name_br,
|
||||
r.way_osm_id,
|
||||
r.way_highway,
|
||||
r.way_type,
|
||||
r.way_oneway,
|
||||
r.way_ref,
|
||||
r.way_name_fr,
|
||||
r.way_name_br,
|
||||
u.the_geom
|
||||
FROM phase_5_pk_ref r FULL JOIN phase_5_pk_umap u ON r.pk_id = u.pk_id
|
||||
WHERE u.pk_id IS NOT NULL
|
||||
ORDER BY r.pk_id ;
|
||||
|
||||
|
||||
-- on calcule les coordonnées
|
||||
|
||||
|
|
@ -1,67 +0,0 @@
|
|||
#!/bin/bash
|
||||
|
||||
# ce traitement consiste à exporter le tracé phase 3 qui a été recalculer
|
||||
# avec un nommage phase 5
|
||||
# puis pusk vers le serveur
|
||||
|
||||
|
||||
set -e
|
||||
set -u
|
||||
|
||||
#PSQL=/usr/bin/psql
|
||||
PSQL=psql
|
||||
DB_HOST=breizhpolenovo
|
||||
DB_NAME=redadeg
|
||||
DB_USER=redadeg
|
||||
DB_PASS=redadeg
|
||||
|
||||
|
||||
|
||||
# ++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++
|
||||
# et on exporte en geojson pour umap et merour
|
||||
|
||||
echo ""
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " Exports"
|
||||
echo ""
|
||||
|
||||
echo " exports geojson"
|
||||
echo ""
|
||||
|
||||
rm data/phase_5_trace_secteurs.geojson
|
||||
ogr2ogr -f "GeoJSON" data/phase_5_trace_secteurs.geojson PG:"host=$DB_HOST user=$DB_USER password=$DB_PASS dbname=$DB_NAME" \
|
||||
-sql "SELECT * FROM phase_3_trace_secteurs_4326 ORDER BY secteur_id"
|
||||
|
||||
rm data/phase_5_trace_troncons.geojson
|
||||
ogr2ogr -f "GeoJSON" data/phase_5_trace_troncons.geojson PG:"host=$DB_HOST user=$DB_USER password=$DB_PASS dbname=$DB_NAME" \
|
||||
-sql "SELECT * FROM phase_3_trace_troncons_4326 ORDER BY troncon_id"
|
||||
|
||||
|
||||
echo " exports GML"
|
||||
echo ""
|
||||
|
||||
rm data/phase_2_trace_pgr.gml
|
||||
ogr2ogr -f "GML" data/phase_2_trace_pgr.gml PG:"host=$DB_HOST user=$DB_USER password=$DB_PASS dbname=$DB_NAME" \
|
||||
-sql "SELECT * FROM phase_2_trace_pgr ORDER BY secteur_id, path_seq"
|
||||
|
||||
|
||||
|
||||
echo " fait"
|
||||
echo ""
|
||||
|
||||
echo " pousse vers serveur"
|
||||
echo ""
|
||||
|
||||
rsync -av -z data/phase_5_trace_secteurs.geojson data/phase_5_trace_troncons.geojson data/phase_2_trace_pgr.gml breizhpovh2:/data/www/vhosts/ar-redadeg_openstreetmap_bzh/htdocs/scripts/data/
|
||||
|
||||
echo ""
|
||||
echo " fait"
|
||||
echo ""
|
||||
|
||||
|
||||
echo ""
|
||||
echo ""
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " F I N"
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo ""
|
File diff suppressed because it is too large
Load diff
|
@ -1,32 +0,0 @@
|
|||
#!/bin/bash
|
||||
|
||||
|
||||
set -e
|
||||
set -u
|
||||
|
||||
|
||||
|
||||
./traitements_phase_1.sh
|
||||
|
||||
|
||||
./create_osm_roads.sh
|
||||
# import du tracé phase 1 dans la base OSM
|
||||
# extraction du réseau de voies à proximité
|
||||
# chargement de la couche osm_roads dans la base redadeg
|
||||
|
||||
|
||||
./create_osm_roads_pgr.sh
|
||||
# à utiliser si on veut complètement recréer un graphe routier à neuf
|
||||
|
||||
|
||||
./update_osm_roads_pgr.sh
|
||||
# maj des couches de routage
|
||||
|
||||
|
||||
psql -h localhost -U redadeg -d redadeg < patch_osm_roads_pgr.sql ;
|
||||
# patch du filaire de voies
|
||||
|
||||
|
||||
./traitements_phase_2.sh
|
||||
|
||||
|
|
@ -1,80 +0,0 @@
|
|||
#!/bin/bash
|
||||
|
||||
set -e
|
||||
set -u
|
||||
|
||||
# argument 1 = millesime redadeg
|
||||
millesime=$1
|
||||
|
||||
PSQL=/usr/bin/psql
|
||||
DB_HOST=localhost
|
||||
DB_NAME=redadeg_$millesime
|
||||
DB_USER=redadeg
|
||||
DB_PASSWD=redadeg
|
||||
|
||||
|
||||
echo "++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++"
|
||||
echo " Mise à jour des couches de routage"
|
||||
echo ""
|
||||
echo " prend 15-20 min"
|
||||
echo ""
|
||||
|
||||
# la couche osm_roads vient d'être mise à jour ou recrée
|
||||
|
||||
# on efface la topologie existante
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME -c "SELECT DropTopology('osm_roads_topo') ;"
|
||||
|
||||
# création d'un schéma qui va accueillir le réseau topologique de la couche osm_roads
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME -c "SELECT topology.CreateTopology('osm_roads_topo', 2154);"
|
||||
|
||||
# ajout d'un nouvel attribut sur la table osm_roads
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME -c "SELECT topology.AddTopoGeometryColumn('osm_roads_topo', 'public', 'osm_roads', 'topo_geom', 'LINESTRING');"
|
||||
|
||||
|
||||
# on a besoin du layer_id
|
||||
# au cas où ça change : on le récupère par requête
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -X -h $DB_HOST -U $DB_USER -d $DB_NAME \
|
||||
-c "SELECT layer_id FROM topology.layer WHERE table_name = 'osm_roads' ;" \
|
||||
--single-transaction \
|
||||
--set AUTOCOMMIT=off \
|
||||
--set ON_ERROR_STOP=on \
|
||||
--no-align \
|
||||
-t \
|
||||
--field-separator ' ' \
|
||||
--quiet | while read -a Record ; do
|
||||
|
||||
layer_id=${Record[0]}
|
||||
|
||||
echo ""
|
||||
echo "layer_id de osm_roads = $layer_id"
|
||||
echo ""
|
||||
|
||||
done
|
||||
|
||||
# sauf que je n'arrive pas à sortir cette valeur du subshell créé par la boucle do /!\
|
||||
# donc je remet ici à la main. A corriger… TODO
|
||||
layer_id=1
|
||||
|
||||
|
||||
# on calcule le graphe topologique 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
|
||||
echo ">> calcul du graphe topologique"
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME -c "UPDATE osm_roads SET topo_geom = topology.toTopoGeom(the_geom, 'osm_roads_topo', $layer_id, 0.00001);"
|
||||
echo ""
|
||||
echo "fait"
|
||||
echo ""
|
||||
|
||||
echo ">> maj de la couche osm_roads_pgr qui sert au routage depuis la topologie"
|
||||
PGPASSWORD=$DB_PASSWD $PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME < update_osm_roads_pgr.sql
|
||||
|
||||
#echo ">> patch de la couche osm_roads_pgr pour les cas particuliers"
|
||||
#$PSQL -h $DB_HOST -U $DB_USER -d $DB_NAME < patch_osm_roads_pgr.sql
|
||||
|
||||
echo "/!\ patcher le filaire de voie si nécessaire"
|
||||
|
||||
echo ""
|
||||
echo "fini"
|
||||
echo ""
|
||||
|
||||
|
|
@ -1,62 +0,0 @@
|
|||
/*
|
||||
==========================================================================
|
||||
|
||||
phase 2 : Mise à jour des couches de routage
|
||||
|
||||
==========================================================================
|
||||
*/
|
||||
|
||||
-- /!\
|
||||
-- cela suppose que la couche osm_roads est à jour !!
|
||||
-- or cette couche est calculée à partir d'une BD osm cf la documentation
|
||||
|
||||
|
||||
-- maj de la couche support des calculs d'itinéraire
|
||||
-- 30 s
|
||||
-- on commence par vider les couches existantes
|
||||
TRUNCATE TABLE osm_roads_pgr ;
|
||||
DROP TABLE IF EXISTS osm_roads_pgr_noded ;
|
||||
DROP TABLE IF EXISTS osm_roads_pgr_vertices_pgr ;
|
||||
|
||||
|
||||
-- reset de la sequence
|
||||
ALTER SEQUENCE public.osm_roads_pgr_noded_id_seq RESTART WITH 1 ;
|
||||
|
||||
-- on remplit la couche de lignes
|
||||
INSERT INTO osm_roads_pgr
|
||||
( SELECT
|
||||
row_number() over() as id,
|
||||
o.osm_id,
|
||||
o.highway,
|
||||
o.type,
|
||||
o.oneway,
|
||||
o.ref,
|
||||
o.name_fr,
|
||||
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,
|
||||
osm_roads o
|
||||
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), reverse_cost = st_length(the_geom);
|
||||
|
||||
|
||||
-- calcul du graphe routier par pgRouting
|
||||
-- cela va remplir les tables osm_roads_pgr_noded et osm_roads_pgr_vertices_pgr
|
||||
-- 30 s
|
||||
SELECT pgr_createTopology('osm_roads_pgr', 0.001);
|
||||
|
||||
-- vérification
|
||||
SELECT pgr_analyzegraph('osm_roads_pgr', 0.001);
|
||||
SELECT pgr_nodeNetwork('osm_roads_pgr', 0.001);
|
||||
|
||||
|
||||
|
Loading…
Reference in a new issue