-
Notifications
You must be signed in to change notification settings - Fork 3
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Browse files
Browse the repository at this point in the history
Update v_treks_schema #15
- Loading branch information
Showing
1 changed file
with
34 additions
and
25 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
|
@@ -6,17 +6,27 @@ DROP VIEW IF EXISTS v_treks_schema; | |
|
||
CREATE VIEW v_treks_schema AS | ||
WITH | ||
-- Constantes à adapter à votre contexte | ||
constants AS ( | ||
SELECT | ||
'https://urlduportailgeotrekrando/' AS url_rando, | ||
'https://urlduportailgeotrekadmin/' AS url_admin, | ||
'[email protected]' AS contact, | ||
'CC-BY-SA-ND' AS default_licence | ||
), | ||
-- Liste des identifiants des relations OpenStreetMap des randonnées si elles existent | ||
osm AS ( | ||
SELECT * FROM (VALUES | ||
--(904197,12076664), -- Exemple d'une randonnée et sa relation dans OSM | ||
(null::int,null::int) | ||
) AS liste (trek_id,id_osm) | ||
), | ||
-- Liste des itinéraires, à adapter à votre contexte si vous souhaitez les filtrer | ||
selected_t AS ( | ||
SELECT * | ||
FROM trekking_trek t | ||
WHERE t.published IS TRUE | ||
JOIN core_topology ct ON ct.id = t.topo_object_id | ||
WHERE t.published IS true and ct.deleted = false | ||
), | ||
sources AS ( | ||
SELECT string_agg(c_1."name", ',')::text AS noms_source, t_1.trek_id -- création d'une chaîne de caractères de toutes les sources de l'itinéraire | ||
|
@@ -51,7 +61,7 @@ WITH | |
ELSE 'autre' | ||
END, | ||
'url', COALESCE( | ||
(SELECT url_admin FROM constants LIMIT 1) || '/media/' || NULLIF(c_1.attachment_file, ''), | ||
(SELECT url_admin FROM constants LIMIT 1) || 'media/' || NULLIF(c_1.attachment_file, ''), | ||
NULLIF(c_1.attachment_link, ''), | ||
c_1.attachment_video | ||
), | ||
|
@@ -72,37 +82,36 @@ WITH | |
JOIN selected_t t ON t.topo_object_id = tnet.trek_id | ||
GROUP BY tnet.trek_id | ||
), | ||
sol AS ( | ||
SELECT string_agg(t_1."name", ',') AS liste, e.topo_object_id | ||
FROM land_physicaledge e | ||
JOIN land_physicaltype t_1 ON e.physical_type_id = t_1.id | ||
JOIN selected_t t ON t.topo_object_id = e.topo_object_id | ||
GROUP BY e.topo_object_id | ||
), | ||
tp AS ( | ||
SELECT practice."name" as practice_name, cirkwi."name" as cirkwi_name, practice.id | ||
FROM trekking_practice practice | ||
LEFT JOIN cirkwi_cirkwilocomotion cirkwi ON cirkwi.id = practice.cirkwi_id | ||
), | ||
parent AS ( | ||
SELECT string_agg(o.parent_id::text, ',') AS liste, t.topo_object_id | ||
FROM trekking_orderedtrekchild o | ||
JOIN selected_t t ON t.topo_object_id = o.child_id | ||
GROUP BY t.topo_object_id | ||
) | ||
SELECT | ||
t.topo_object_id::varchar(250) AS id_local, | ||
sources.noms_source AS producteur, | ||
(SELECT contact FROM constants LIMIT 1) AS contact, -- adresse mail à renseigner dans les constantes | ||
NULL AS uuid, -- pas d'uuid prévu dans Geotrek | ||
-- construction de l'url valable pour Geotrek-rando V2 (voir juste en-dessous pour l'url V3) | ||
top.uuid AS uuid, -- UUID disponibles depuis la version 2.70.0 de Geotrek-admin | ||
-- Construction de l'url valable pour Geotrek-rando V2 (voir juste en-dessous pour l'url V3) | ||
(SELECT url_rando FROM constants LIMIT 1) || lower(unaccent(replace(tp.practice_name, ' ', '-'))) || '/' | ||
|| lower(unaccent(replace(btrim(regexp_replace(t."name", '[^\w -]', '', 'g')), ' ', '-'))) || '/' AS url, | ||
-- construction de l'url valable pour Geotrek-rando V3 : | ||
-- (SELECT url_rando FROM constants LIMIT 1) || 'trek/' || t.topo_object_id || '-' || replace(btrim(regexp_replace(t."name", '[^\w -]', '', 'g')), ' ', '-') AS url, | ||
NULL AS id_osm, | ||
-- Construction de l'url valable pour Geotrek-rando V3 : | ||
-- (SELECT url_rando FROM constants LIMIT 1) || 'trek/' || t.topo_object_id || '-' || replace(btrim(regexp_replace(t."name", '[^\d\w,()]', '', 'g')), ' ', '-') AS url, | ||
osm.id_osm, | ||
t."name" AS nom_itineraire, | ||
tp.practice_name AS pratique, -- uniquement valable si vos noms de pratiques correspondent déjà au schéma, sinon passer par quelque chose comme : CASE WHEN tp.practice_name ILIKE 'Randonnée Trail' THEN 'trail'::text END AS pratique | ||
lower(route.route::text) AS type_itineraire, | ||
lower(route.route::text) AS type_itineraire, -- idem que pour les pratiques, uniquement valable si vos noms de types d'itinéraires correspondent déjà au schéma, sinon passer par un CASE WHEN | ||
c.liste_noms::text AS communes_nom, | ||
c.liste_codes::text AS communes_code, | ||
btrim(t.departure) AS depart, | ||
btrim(t.arrival) AS arrivee, | ||
round(t.duration::numeric,1)::real AS duree, | ||
t.duration::real AS duree, | ||
balisage.b::text AS balisage, | ||
top.length::integer AS longueur, | ||
difficulty.difficulty AS difficulte, | ||
|
@@ -119,32 +128,32 @@ SELECT | |
t.access AS acces_routier, | ||
t.public_transport AS transports, | ||
advised_parking AS parking_info, | ||
ST_AsText(st_snaptogrid(st_transform(parking_location, 4326), 0.000027::double precision)) AS parking_geometrie, | ||
-- Reprojection des géométries en 4326 | ||
ST_AsText(st_transform(parking_location, 4326)) AS parking_geometrie, | ||
date(top.date_insert)::text AS date_creation, | ||
date(top.date_update)::text AS date_modification, | ||
medias.liste AS medias, | ||
parent.parent_id::varchar AS itineraire_parent, | ||
sol.liste::text AS type_sol, | ||
parent.liste::text AS itineraire_parent, | ||
NULL::text AS type_sol, | ||
NULL::boolean AS pdipr_inscription, | ||
NULL::text AS pdipr_date_inscription, | ||
-- réduction de la précision des coordonnées à 5 décimales, simplification de la géométrie pour réduire le nombre de points. Poids de la géométrie divisé par 7.5 | ||
st_simplifypreservetopology(st_snaptogrid(st_transform(top.geom, 4326), 0.000027::double precision), 0.000027::double precision) AS geom | ||
-- Reprojection des géométries en 4326 | ||
st_transform(top.geom, 4326) AS geom | ||
FROM selected_t t | ||
JOIN core_topology top ON t.topo_object_id = top.id | ||
JOIN sources ON t.topo_object_id = sources.trek_id | ||
LEFT JOIN sources ON t.topo_object_id = sources.trek_id | ||
JOIN tp ON tp.id = t.practice_id | ||
LEFT JOIN osm ON t.topo_object_id = osm.trek_id | ||
LEFT JOIN trekking_route route ON t.route_id = route.id | ||
LEFT JOIN trekking_difficultylevel difficulty ON difficulty.id = t.difficulty_id | ||
LEFT JOIN handi ON t.topo_object_id = handi.trek_id | ||
LEFT JOIN trekking_orderedtrekchild parent ON t.topo_object_id = parent.child_id | ||
LEFT JOIN parent ON t.topo_object_id = parent.topo_object_id | ||
LEFT JOIN themes ON t.topo_object_id = themes.trek_id | ||
LEFT JOIN medias ON t.topo_object_id = medias.object_id | ||
LEFT JOIN balisage ON t.topo_object_id = balisage.trek_id | ||
LEFT JOIN sol ON t.topo_object_id = sol.topo_object_id | ||
LEFT JOIN LATERAL ( -- construction des listes des noms de commune et des codes INSEE | ||
SELECT string_agg(z."name", ',') AS liste_noms, string_agg(z.code, ',') AS liste_codes, c_1.id | ||
FROM core_topology c_1 | ||
JOIN zoning_city z ON t.topo_object_id = c_1.id AND st_intersects(c_1.geom, z.geom) | ||
GROUP BY c_1.id | ||
) c ON true; | ||
|