Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Fix data: fix and improve vm_communes #402

Open
wants to merge 2 commits into
base: develop
Choose a base branch
from
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
36 changes: 23 additions & 13 deletions data/atlas/12.atlas.t_mailles_territoire.sql
Original file line number Diff line number Diff line change
@@ -1,19 +1,29 @@
DROP TABLE IF EXISTS atlas.t_mailles_territoire;

-- MV for having only meshs of the territory
CREATE TABLE atlas.t_mailles_territoire AS
WITH areas AS (
SELECT
id_area,
st_transform(c.geom, 4326) AS geom,
geojson_4326 AS geojson
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
)
SELECT
st_transform(a.geom, 4326) AS the_geom,
st_asgeojson(st_transform(a.geom, 4326)) AS geojson_maille,
a.geom AS the_geom,
a.geojson AS geojson_maille,
a.id_area AS id_maille
FROM ref_geo.l_areas AS a
JOIN ref_geo.bib_areas_types AS t
ON t.id_type = a.id_type
JOIN atlas.t_layer_territoire AS l
ON ST_intersects(a.geom, st_transform(l.the_geom, find_srid('ref_geo', 'l_areas', 'geom')))
WHERE a.enable = true
AND t.type_code = :type_maille ;
FROM areas AS a
WHERE EXISTS (
SELECT 'X'
FROM atlas.vm_subdivided_area AS sa
WHERE sa.code = 'territory'
AND st_intersects(a.geom, sa.geom)
);

CREATE UNIQUE INDEX ON atlas.t_mailles_territoire
USING btree (id_maille);
CREATE INDEX ON atlas.t_mailles_territoire
USING spgist (the_geom);
CREATE UNIQUE INDEX ON atlas.t_mailles_territoire USING btree (id_maille);
CREATE INDEX ON atlas.t_mailles_territoire USING spgist (the_geom);
24 changes: 16 additions & 8 deletions data/atlas/7.atlas.vm_communes.sql
Original file line number Diff line number Diff line change
@@ -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);
39 changes: 33 additions & 6 deletions data/gn2/atlas_ref_geo.sql
Original file line number Diff line number Diff line change
Expand Up @@ -33,11 +33,10 @@ CREATE UNIQUE INDEX l_communes_insee_idx
(insee COLLATE pg_catalog."default");


--################################
--################################
--###Mailles
--################################
--################################


DO $$
BEGIN
Expand All @@ -46,11 +45,10 @@ EXCEPTION WHEN others THEN
RAISE NOTICE 'view atlas.t_mailles_territoire does not exist';
END$$;

--################################
--################################
--###Territoires
--################################
--################################


DO $$
BEGIN
Expand Down Expand Up @@ -81,19 +79,48 @@ 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()
RETURNS VOID AS $$
BEGIN

REFRESH MATERIALIZED VIEW atlas.t_layer_territoire;
REFRESH MATERIALIZED VIEW atlas.t_mailles_territoire;
Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

atlas.t_mailles_territoire est une table. Le rafraichissement dessus ne marche pas. J'ai donc supprimé cette ligne. Mais, il faudrait peut être transformer cette table en VM ?

REFRESH MATERIALIZED VIEW atlas.vm_subdivided_area;
REFRESH MATERIALIZED VIEW atlas.l_communes;
REFRESH MATERIALIZED VIEW atlas.vm_communes;

Expand Down
45 changes: 45 additions & 0 deletions data/update/update_vm_subdivided_area.sql
Original file line number Diff line number Diff line change
@@ -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'
Comment on lines +39 to +42
Copy link
Contributor Author

Choose a reason for hiding this comment

The reason will be displayed to describe this comment to others. Learn more.

Point à traiter suite au merge avec la branche develop.



COMMIT;
Loading