first shot
This commit is contained in:
commit
e5fb324f3d
20
create_database.sh
Executable file
20
create_database.sh
Executable file
|
@ -0,0 +1,20 @@
|
|||
#!/bin/sh
|
||||
|
||||
|
||||
# utiliser un compte SUPERUSER pour exécuter ce script
|
||||
|
||||
# create role
|
||||
createuser -l -S redadeg
|
||||
# password
|
||||
psql -d postgres -c "ALTER USER redadeg WITH PASSWORD 'redadeg';"
|
||||
|
||||
# create database with owner redadeg
|
||||
createdb -E UTF8 -O redadeg redadeg
|
||||
|
||||
# postgis extension
|
||||
psql -d redadeg -c "CREATE EXTENSION postgis;"
|
||||
|
||||
|
||||
# create tables
|
||||
#psql -d redadeg -U redadeg -Wredadeg -c ";"
|
||||
|
82
create_tables_3948.sql
Normal file
82
create_tables_3948.sql
Normal file
|
@ -0,0 +1,82 @@
|
|||
|
||||
-- on est obligé de créer des tables en 3948
|
||||
-- car même si les tables original 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 3948 on est sûr des longueurs
|
||||
|
||||
|
||||
DROP TABLE phase_1_trace_3948 ;
|
||||
CREATE TABLE phase_1_trace_3948
|
||||
(
|
||||
ogc_fid integer,
|
||||
name text,
|
||||
description text,
|
||||
the_geom geometry(LineString,3948),
|
||||
CONSTRAINT phase_1_trace_3948_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) = 3948)
|
||||
);
|
||||
|
||||
DROP TABLE phase_1_pk_vip_3948 ;
|
||||
CREATE TABLE phase_1_pk_vip_3948
|
||||
(
|
||||
ogc_fid integer,
|
||||
name text,
|
||||
description text,
|
||||
the_geom geometry(Point,3948),
|
||||
CONSTRAINT phase_1_pk_vip_3948_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) = 3948)
|
||||
);
|
||||
|
||||
|
||||
|
||||
-- table des tronçons créés à partir des longs tracés
|
||||
DROP TABLE phase_1_trace_troncons_3948 ;
|
||||
CREATE TABLE phase_1_trace_troncons_3948
|
||||
(
|
||||
uid bigint,
|
||||
secteur character varying(25),
|
||||
km bigint,
|
||||
km_reel bigint,
|
||||
longueur integer,
|
||||
the_geom geometry(LineString,3948),
|
||||
CONSTRAINT phase_1_trace_troncons_3948_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) = 3948)
|
||||
);
|
||||
|
||||
-- table des PK auto en fin de tronçon
|
||||
/*DROP TABLE phase_1_pk_auto_3948 ;
|
||||
CREATE TABLE phase_1_pk_auto_3948
|
||||
(
|
||||
uid bigint,
|
||||
secteur character varying(25),
|
||||
km bigint,
|
||||
km_reel bigint,
|
||||
the_geom geometry(Point,3948),
|
||||
CONSTRAINT phase_1_pk_auto_3948_pkey PRIMARY KEY (uid),
|
||||
CONSTRAINT enforce_geotype_the_geom CHECK (geometrytype(the_geom) = 'POINT'::text),
|
||||
CONSTRAINT enforce_srid_the_geom CHECK (st_srid(the_geom) = 3948)
|
||||
);*/
|
||||
|
||||
-- vue des PK auto en fin de tronçon
|
||||
CREATE VIEW phase_1_pk_auto_3948 AS
|
||||
SELECT
|
||||
uid, secteur, km, km_reel,
|
||||
ST_Line_Interpolate_Point(the_geom, 1)::geometry(Point, 3948) AS the_geom
|
||||
FROM phase_1_trace_troncons_3948 ;
|
||||
|
||||
-- la même mais en 4326 pour export
|
||||
--DROP VIEW phase_1_pk_auto_4326 ;
|
||||
CREATE VIEW phase_1_pk_auto_4326 AS
|
||||
SELECT
|
||||
uid, secteur, km, km_reel,
|
||||
ST_Transform(the_geom,4326)::geometry(Point, 4326) AS the_geom
|
||||
FROM phase_1_pk_auto_3948 ;
|
||||
|
||||
|
||||
|
||||
|
||||
|
34
geojson_to_postgis.sh
Executable file
34
geojson_to_postgis.sh
Executable file
|
@ -0,0 +1,34 @@
|
|||
#!/bin/sh
|
||||
|
||||
|
||||
# ++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++
|
||||
# on récupère les couches geojson depuis umap
|
||||
|
||||
# le tracé manuel
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/715180/ > phase_1_trace.geojson
|
||||
# PK VIP
|
||||
curl -sS http://umap.openstreetmap.fr/fr/datalayer/715179/ > phase_1_pk_vip.geojson
|
||||
|
||||
|
||||
# ++++++++++++++++++++++++++++++++++++++++++++++++++++++++++++
|
||||
# on charge dans postgis
|
||||
# après avoir supprimé les tables
|
||||
|
||||
# note : les coordonnées sont en 3857 maisla déclaration de la table = 4326
|
||||
|
||||
psql -d redadeg -c "DROP TABLE phase_1_trace_3857 CASCADE;"
|
||||
ogr2ogr -f "PostgreSQL" PG:"host=localhost user=redadeg password=redadeg dbname=redadeg" phase_1_trace.geojson -nln phase_1_trace_3857 -lco GEOMETRY_NAME=the_geom
|
||||
|
||||
psql -d redadeg -c "DROP TABLE phase_1_pk_vip_3857;"
|
||||
ogr2ogr -f "PostgreSQL" PG:"host=localhost user=redadeg password=redadeg dbname=redadeg" phase_1_pk_vip.geojson -nln phase_1_pk_vip_3857 -lco GEOMETRY_NAME=the_geom
|
||||
|
||||
|
||||
# on crée les tables en 3948
|
||||
psql -d redadeg < load_tables_3948.sql
|
||||
|
||||
|
||||
# et on exporte vers Geojson
|
||||
ogr2ogr -f "GeoJSON" phase_1_pk_auto.geojson PG:"host=localhost user=redadeg password=redadeg dbname=redadeg" phase_1_pk_auto_4326
|
||||
|
||||
# les fichiers sont ensuite tout de suite visible dans umap
|
||||
|
48
load_tables_3948.sql
Normal file
48
load_tables_3948.sql
Normal file
|
@ -0,0 +1,48 @@
|
|||
|
||||
|
||||
TRUNCATE phase_1_trace_3948 ;
|
||||
INSERT INTO phase_1_trace_3948
|
||||
SELECT ogc_fid, name, '', ST_Transform(the_geom,3948) AS the_geom
|
||||
FROM phase_1_trace_3857 ;
|
||||
|
||||
|
||||
TRUNCATE phase_1_pk_vip_3948 ;
|
||||
INSERT INTO phase_1_pk_vip_3948
|
||||
SELECT ogc_fid, name, description, ST_Transform(the_geom,3948) AS the_geom
|
||||
FROM phase_1_pk_vip_3857 ;
|
||||
|
||||
|
||||
TRUNCATE phase_1_trace_troncons_3948 ;
|
||||
INSERT INTO phase_1_trace_troncons_3948
|
||||
SELECT
|
||||
row_number() over() as uid,
|
||||
NULL AS secteur,
|
||||
NULL AS km,
|
||||
NULL AS km_reel,
|
||||
NULL AS longueur,
|
||||
ST_LineSubstring(the_geom, 940.00*n/length,
|
||||
CASE
|
||||
WHEN 940.00*(n+1) < length THEN 940.00*(n+1)/length
|
||||
ELSE 1
|
||||
END) AS the_geom
|
||||
FROM
|
||||
(SELECT
|
||||
ogc_fid,
|
||||
ST_LineMerge(the_geom)::geometry(LineString,3948) AS the_geom,
|
||||
ST_Length(the_geom) As length
|
||||
FROM phase_1_trace_3948
|
||||
) AS t
|
||||
CROSS JOIN generate_series(0,10000) AS n
|
||||
WHERE n*940.00/length < 1 ;
|
||||
|
||||
-- mise à jour des attributs
|
||||
UPDATE phase_1_trace_troncons_3948
|
||||
SET
|
||||
longueur =
|
||||
(
|
||||
CASE
|
||||
WHEN TRUNC( ST_Length(the_geom)::numeric , 0) = 939 THEN 940
|
||||
ELSE TRUNC( ST_Length(the_geom)::numeric , 0)
|
||||
END
|
||||
)
|
||||
|
Loading…
Reference in a new issue