diff --git a/data/atlas/12.atlas.t_mailles_territoire.sql b/data/atlas/12.atlas.t_mailles_territoire.sql index f07a573e..38c9763e 100644 --- a/data/atlas/12.atlas.t_mailles_territoire.sql +++ b/data/atlas/12.atlas.t_mailles_territoire.sql @@ -1,14 +1,21 @@ DROP TABLE IF EXISTS atlas.t_mailles_territoire; -- MV for having only meshs of the territory -CREATE TABLE atlas.t_mailles_territoire -AS SELECT -st_transform(c.geom, 4326) AS the_geom, -st_asgeojson(st_transform(c.geom, 4326)) AS geojson_maille, -c.id_area AS id_maille -FROM ref_geo.l_areas c -JOIN ref_geo.bib_areas_types t ON t.id_type = c.id_type -JOIN atlas.t_layer_territoire mt ON ST_intersects(c.geom,st_transform(mt.the_geom, 2154)) -WHERE c.enable = true AND t.type_code = :type_maille; +CREATE TABLE atlas.t_mailles_territoire AS + SELECT + st_transform(c.geom, 4326) AS the_geom, + st_asgeojson(st_transform(c.geom, 4326)) AS geojson_maille, + c.id_area AS id_maille + FROM ref_geo.l_areas AS c + JOIN ref_geo.bib_areas_types AS t + ON t.id_type = c.id_type + WHERE c.enable = true + AND t.type_code = :type_maille + AND EXISTS ( + SELECT 'X' + FROM atlas.vm_subdivided_area AS sa + WHERE sa.code = 'territory' + AND st_intersects(st_transform(sa.geom, 2154), c.geom) + ); -CREATE UNIQUE INDEX t_mailles_territoire_id_maille_idx ON atlas.t_mailles_territoire USING btree (id_maille); \ No newline at end of file +CREATE UNIQUE INDEX t_mailles_territoire_id_maille_idx ON atlas.t_mailles_territoire USING btree (id_maille); diff --git a/data/atlas/7.atlas.vm_communes.sql b/data/atlas/7.atlas.vm_communes.sql index 99f3bcd9..1a3787eb 100644 --- a/data/atlas/7.atlas.vm_communes.sql +++ b/data/atlas/7.atlas.vm_communes.sql @@ -1,12 +1,20 @@ -- Communes contenues entièrement dans le territoire CREATE MATERIALIZED VIEW atlas.vm_communes AS -SELECT c.insee, -c.commune_maj, -c.the_geom, -st_asgeojson(st_transform(c.the_geom, 4326)) as commune_geojson -FROM atlas.l_communes c -JOIN atlas.t_layer_territoire t ON ST_CONTAINS(ST_BUFFER(t.the_geom,200), c.the_geom); + SELECT + c.insee, + c.commune_maj, + c.the_geom, + st_asgeojson(st_transform(c.the_geom, 4326)) AS commune_geojson + FROM atlas.l_communes AS c + WHERE EXISTS ( + SELECT 'X' + FROM atlas.vm_subdivided_area AS sa + WHERE sa.code = 'territory_buffer-200' + AND st_intersects(sa.geom, c.the_geom) + ) + WITH DATA; + +CREATE UNIQUE INDEX ON atlas.vm_communes (insee) ; +CREATE INDEX index_gist_vm_communes_the_geom ON atlas.vm_communes USING gist (the_geom) ; -CREATE UNIQUE INDEX ON atlas.vm_communes (insee); -CREATE INDEX index_gist_vm_communes_the_geom ON atlas.vm_communes USING gist (the_geom); diff --git a/data/gn2/atlas_ref_geo.sql b/data/gn2/atlas_ref_geo.sql index 79fdd086..5f50dd45 100644 --- a/data/gn2/atlas_ref_geo.sql +++ b/data/gn2/atlas_ref_geo.sql @@ -33,11 +33,10 @@ CREATE UNIQUE INDEX l_communes_insee_idx (insee COLLATE pg_catalog."default"); ---################################ --################################ --###Mailles --################################ ---################################ + DO $$ BEGIN @@ -46,11 +45,10 @@ EXCEPTION WHEN others THEN RAISE NOTICE 'view atlas.t_mailles_territoire does not exist'; END$$; ---################################ --################################ --###Territoires --################################ ---################################ + DO $$ BEGIN @@ -81,11 +79,40 @@ CREATE INDEX index_gist_t_layer_territoire_the_geom ON atlas.t_layer_territoire USING gist (the_geom); - + CREATE UNIQUE INDEX t_layer_territoire_gid_idx ON atlas.t_layer_territoire USING btree (gid); +--################################ +--### Subdivision de zones +--################################ + +DROP MATERIALIZED VIEW IF EXISTS atlas.vm_subdivided_area ; + +CREATE MATERIALIZED VIEW atlas.vm_subdivided_area AS + SELECT + random() AS gid, + 'territory' AS code, + st_subdivide(t.the_geom, 255) AS geom + FROM atlas.t_layer_territoire AS t + + UNION + + SELECT + random() AS gid, + 'territory_buffer-200' AS code, + st_subdivide(st_buffer(t.the_geom::geography, -200)::geometry, 255) AS geom + FROM atlas.t_layer_territoire AS t +WITH DATA; + +CREATE UNIQUE INDEX ON atlas.vm_subdivided_area USING btree (gid); +CREATE INDEX ON atlas.vm_subdivided_area USING btree (code); +CREATE INDEX ON atlas.vm_subdivided_area USING gist (geom); + +--################################ +--### Fonctions +--################################ -- Rafraichissement des vues contenant les données de l'atlas CREATE OR REPLACE FUNCTION atlas.refresh_materialized_view_ref_geo() @@ -93,7 +120,7 @@ RETURNS VOID AS $$ BEGIN REFRESH MATERIALIZED VIEW atlas.t_layer_territoire; - REFRESH MATERIALIZED VIEW atlas.t_mailles_territoire; + REFRESH MATERIALIZED VIEW atlas.vm_subdivided_area; REFRESH MATERIALIZED VIEW atlas.l_communes; REFRESH MATERIALIZED VIEW atlas.vm_communes; diff --git a/data/update/update_vm_subdivided_area.sql b/data/update/update_vm_subdivided_area.sql new file mode 100644 index 00000000..c0c03738 --- /dev/null +++ b/data/update/update_vm_subdivided_area.sql @@ -0,0 +1,45 @@ +BEGIN; + +CREATE MATERIALIZED VIEW atlas.vm_subdivided_area AS + SELECT + random() AS gid, + 'territory' AS code, + st_subdivide(t.the_geom, 255) AS geom + FROM atlas.t_layer_territoire AS t + + UNION + + SELECT + random() AS gid, + 'territory_buffer-200' AS code, + st_subdivide(st_buffer(t.the_geom::geography, -200)::geometry, 255) AS geom + FROM atlas.t_layer_territoire AS t +WITH DATA; + +CREATE UNIQUE INDEX ON atlas.vm_subdivided_area USING btree (gid); +CREATE INDEX ON atlas.vm_subdivided_area USING btree (code); +CREATE INDEX ON atlas.vm_subdivided_area USING gist (geom); + + +DROP FUNCTION IF EXISTS atlas.refresh_materialized_view_ref_geo; + +CREATE OR REPLACE FUNCTION atlas.refresh_materialized_view_ref_geo() +RETURNS VOID AS $$ +BEGIN + + REFRESH MATERIALIZED VIEW atlas.t_layer_territoire; + REFRESH MATERIALIZED VIEW atlas.vm_subdivided_area; + REFRESH MATERIALIZED VIEW atlas.l_communes; + REFRESH MATERIALIZED VIEW atlas.vm_communes; + +END +$$ LANGUAGE plpgsql; + + +-- TODO : ajouter ce script au futur script d'update de GeoNature Atlas. +-- TODO : trouver une solution pour pouvoir regénérer les VMs et table via les scripts présent dans data/atlas/. +-- TODO : il faudrait aussi relancer la génération de la VM vm_communes à l'aide du script '7.atlas.vm_communes.sql +-- TODO : il faudrait aussi relancer la génération de la table t_mailles_territoire à l'aide du script '12.atlas.t_mailles_teritoire.sql' + + +COMMIT;