Skip to content

Commit

Permalink
Feat install: improve blurring and performances for syntheseff view
Browse files Browse the repository at this point in the history
Resolve #390.
  • Loading branch information
jpm-cbna committed Dec 7, 2023
1 parent 5a918b1 commit 9f30331
Show file tree
Hide file tree
Showing 8 changed files with 239 additions and 56 deletions.
8 changes: 6 additions & 2 deletions atlas/configuration/settings.ini.sample
Original file line number Diff line number Diff line change
Expand Up @@ -35,11 +35,11 @@ owner_atlas_pass=monpassachanger
geonature_source=true

# L'atlas est-il en lien avec le référentiel géographique de GeoNature (ref_geo) ?
# ATTENTION : Doit être égal à true si geonature_source=true,
# ATTENTION : Doit être égal à true si geonature_source=true,
# ATTENTION : Doit être égal à false si geonature_source=false
use_ref_geo_gn2=true

# Souhaitez-vous installer le schéma taxonomie de TaxHub dans la BDD de GeoNature-atlas ?
# Souhaitez-vous installer le schéma taxonomie de TaxHub dans la BDD de GeoNature-atlas ?
# false si vous souhaitez utiliser celui de GeoNature en FDW
# ATTENTION : Doit être true si geonature_source=false
install_taxonomie=false
Expand All @@ -61,6 +61,10 @@ db_source_port=5432
# Nom de la BDD GeoNature source
db_source_name=geonature2db

# Taille du nombre d'éléments à récupérer à la fois pour Foreign Data Wrapper (défaut 100)
# Note : utiliser 1000000 pour une table synthese avec plusieurs millions d'observations.
db_source_fetch_size=100

# Nom de l'utilisateur atlas dans la BDD GeoNature source (lecture seule)
atlas_source_user=geonatatlas

Expand Down
1 change: 1 addition & 0 deletions data/atlas/14.grant.sql
Original file line number Diff line number Diff line change
Expand Up @@ -20,6 +20,7 @@ GRANT ALL ON TABLE spatial_ref_sys TO my_reader_user;*/

GRANT USAGE ON SCHEMA atlas TO my_reader_user;

GRANT SELECT ON TABLE synthese.vm_cor_synthese_area TO my_reader_user
GRANT SELECT ON TABLE atlas.vm_altitudes TO my_reader_user;
GRANT SELECT ON TABLE atlas.vm_communes TO my_reader_user;
GRANT SELECT ON TABLE atlas.vm_observations TO my_reader_user;
Expand Down
3 changes: 2 additions & 1 deletion data/atlas/2.atlas.vm_observations.sql
Original file line number Diff line number Diff line change
Expand Up @@ -10,7 +10,8 @@ CREATE MATERIALIZED VIEW atlas.vm_observations AS
s.the_geom_point,
s.effectif_total,
tx.cd_ref,
st_asgeojson(st_transform(s.the_geom_point, 4326)) as geojson_point,
st_asgeojson(s.the_geom_point) as geojson_point,
s.sensitivity,
s.diffusion_level,
s.id_dataset
FROM synthese.syntheseff s
Expand Down
2 changes: 2 additions & 0 deletions data/atlas/atlas.refresh_materialized_view_data.sql
Original file line number Diff line number Diff line change
Expand Up @@ -23,6 +23,8 @@ CREATE OR REPLACE FUNCTION atlas.refresh_materialized_view_data()
RETURNS VOID AS $$
BEGIN

REFRESH MATERIALIZED VIEW CONCURRENTLY synthese.vm_cor_synthese_area;

REFRESH MATERIALIZED VIEW CONCURRENTLY atlas.vm_observations;
REFRESH MATERIALIZED VIEW CONCURRENTLY atlas.vm_observations_mailles;
REFRESH MATERIALIZED VIEW CONCURRENTLY atlas.vm_cor_taxon_organism;
Expand Down
13 changes: 7 additions & 6 deletions data/atlas/without_geonature.sql
Original file line number Diff line number Diff line change
@@ -1,6 +1,6 @@
CREATE TABLE synthese.syntheseff(
id_synthese serial PRIMARY KEY,
id_organism integer DEFAULT 2,
id_organism integer DEFAULT 2,
id_dataset integer,
cd_nom integer,
insee character(5),
Expand All @@ -10,15 +10,16 @@ CREATE TABLE synthese.syntheseff(
supprime boolean DEFAULT false,
the_geom_point geometry('POINT',4326),
effectif_total integer,
diffusion_level integer
diffusion_level integer,
sensitivity integer
);

INSERT INTO synthese.syntheseff
(cd_nom, insee, observateurs, altitude_retenue, the_geom_point, effectif_total, diffusion_level)
VALUES (67111, 05122, 'Mon observateur', 1254, ST_SetSRID( ST_Point( 6, 42.315), 4326), 3, 5);
(cd_nom, insee, observateurs, altitude_retenue, the_geom_point, effectif_total, diffusion_level, sensitivity)
VALUES (67111, 05122, 'Mon observateur', 1254, ST_SetSRID( ST_Point( 6, 42.315), 4326), 3, 5, 0);
INSERT INTO synthese.syntheseff
(cd_nom, insee, observateurs, altitude_retenue, the_geom_point, effectif_total, diffusion_level)
VALUES (67111, 05122, 'Mon observateur 3', 940, ST_SetSRID( ST_Point( 6.1, 42.315), 4326), 2, 5);
(cd_nom, insee, observateurs, altitude_retenue, the_geom_point, effectif_total, diffusion_level, sensitivity)
VALUES (67111, 05122, 'Mon observateur 3', 940, ST_SetSRID( ST_Point( 6.1, 42.315), 4326), 2, 5, 0);


CREATE TABLE gn_meta.cor_dataset_actor (
Expand Down
132 changes: 86 additions & 46 deletions data/gn2/atlas_synthese.sql
Original file line number Diff line number Diff line change
@@ -1,50 +1,90 @@
-- Creation d'une vue permettant de reproduire le contenu de la table du même nom dans les versions précédentes

CREATE VIEW synthese.syntheseff AS
WITH areas AS (
CREATE MATERIALIZED VIEW synthese.vm_cor_synthese_area
TABLESPACE pg_default
AS
SELECT DISTINCT ON (sa.id_synthese, t.type_code)
sa.id_synthese,
sa.id_area,
a.centroid,
st_transform(centroid, 4326) as centroid_4326,
t.type_code
FROM synthese.cor_area_synthese sa
JOIN ref_geo.l_areas a ON sa.id_area = a.id_area
JOIN ref_geo.bib_areas_types t ON a.id_type = t.id_type
WHERE type_code IN ('M10', 'COM', 'DEP')
), obs_data AS (
SELECT s.id_synthese,
s.cd_nom,
s.id_dataset,
s.date_min AS dateobs,
s.observers AS observateurs,
(s.altitude_min + s.altitude_max) / 2 AS altitude_retenue,
CASE
WHEN dl.cd_nomenclature = '1' THEN
(SELECT centroid_4326 FROM areas a WHERE a.id_synthese = s.id_synthese AND type_code = 'COM' LIMIT 1)
WHEN dl.cd_nomenclature = '2' THEN
(SELECT centroid_4326 FROM areas a WHERE a.id_synthese = s.id_synthese AND type_code = 'M10' LIMIT 1)
WHEN dl.cd_nomenclature = '3' THEN
(SELECT centroid_4326 FROM areas a WHERE a.id_synthese = s.id_synthese AND type_code = 'DEP' LIMIT 1)
sa.id_synthese,
sa.id_area,
st_transform(a.centroid, 4326) AS centroid_4326,
t.type_code,
a.area_code
FROM synthese.cor_area_synthese AS sa
JOIN ref_geo.l_areas AS a
ON (sa.id_area = a.id_area)
JOIN ref_geo.bib_areas_types AS t
ON (a.id_type = t.id_type)
WHERE t.type_code IN ('M10', 'COM', 'DEP')
WITH DATA;

-- View indexes:
CREATE UNIQUE INDEX ON synthese.vm_cor_synthese_area (id_synthese, id_area);
CREATE INDEX ON synthese.vm_cor_synthese_area (type_code);


VACUUM ANALYSE synthese.vm_cor_synthese_area;


CREATE OR REPLACE FUNCTION atlas.get_blurring_centroid_geom_by_code(code CHARACTER VARYING, idSynthese INTEGER)
RETURNS geometry
LANGUAGE plpgsql
IMMUTABLE
AS $function$
-- Function which return the centroid for a sensitivity or diffusion_level code and a synthese id
DECLARE centroid geometry;

BEGIN
SELECT INTO centroid csa.centroid_4326
FROM synthese.vm_cor_synthese_area AS csa
WHERE csa.id_synthese = idSynthese
AND csa.type_code = (CASE WHEN code = '1' THEN 'COM' WHEN code = '2' THEN 'M10' WHEN code = '3' THEN 'DEP' END)
LIMIT 1 ;

RETURN centroid ;
END;
$function$
;

CREATE VIEW synthese.syntheseff AS
SELECT
s.id_synthese,
s.id_dataset,
s.cd_nom,
s.date_min AS dateobs,
s.observers AS observateurs,
(s.altitude_min + s.altitude_max) / 2 AS altitude_retenue,
CASE
WHEN (sens.cd_nomenclature::INT >= 1 AND sens.cd_nomenclature::INT <= 3 AND dl.cd_nomenclature::INT >= 1 AND dl.cd_nomenclature::INT <= 3) THEN
CASE
WHEN (sens.cd_nomenclature::INT >= dl.cd_nomenclature::INT) THEN (
atlas.get_blurring_centroid_geom_by_code(sens.cd_nomenclature, s.id_synthese)
)
WHEN (sens.cd_nomenclature::INT < dl.cd_nomenclature::INT) THEN (
atlas.get_blurring_centroid_geom_by_code(dl.cd_nomenclature, s.id_synthese)
)
END
WHEN (sens.cd_nomenclature::INT >= 1 AND sens.cd_nomenclature::INT <= 3) AND (dl.cd_nomenclature::INT < 1 OR dl.cd_nomenclature::INT > 3) THEN (
atlas.get_blurring_centroid_geom_by_code(sens.cd_nomenclature, s.id_synthese)
)
WHEN (dl.cd_nomenclature::INT >= 1 AND dl.cd_nomenclature::INT <= 3) AND (sens.cd_nomenclature::INT < 1 OR sens.cd_nomenclature::INT > 3) THEN (
atlas.get_blurring_centroid_geom_by_code(dl.cd_nomenclature, s.id_synthese)
)
ELSE st_transform(s.the_geom_point, 4326)
END AS the_geom_point,
s.count_min AS effectif_total,
dl.cd_nomenclature::int as diffusion_level
FROM synthese.synthese s
LEFT OUTER JOIN synthese.t_nomenclatures dl ON s.id_nomenclature_diffusion_level = dl.id_nomenclature
LEFT OUTER JOIN synthese.t_nomenclatures st ON s.id_nomenclature_observation_status = st.id_nomenclature
WHERE (NOT dl.cd_nomenclature = '4'::text OR id_nomenclature_diffusion_level IS NULL) -- Filtre données non diffusable code "4" ou pas de diffusion spécifiée
AND st.cd_nomenclature = 'Pr'-- seulement les données présentes (status_observation = )
)
SELECT d.id_synthese,
d.id_dataset,
d.cd_nom,
d.dateobs,
d.observateurs,
d.altitude_retenue,
d.the_geom_point,
d.effectif_total,
c.insee,
diffusion_level
FROM obs_data d
JOIN atlas.l_communes c ON st_intersects(d.the_geom_point, c.the_geom);
END AS the_geom_point,
s.count_min AS effectif_total,
areas.area_code AS insee,
sens.cd_nomenclature AS sensitivity,
dl.cd_nomenclature AS diffusion_level
FROM synthese.synthese s
JOIN synthese.vm_cor_synthese_area AS areas
ON (s.id_synthese = areas.id_synthese)
LEFT JOIN synthese.t_nomenclatures AS sens
ON (s.id_nomenclature_sensitivity = sens.id_nomenclature)
LEFT JOIN synthese.t_nomenclatures AS dl
ON (s.id_nomenclature_diffusion_level = dl.id_nomenclature)
LEFT JOIN synthese.t_nomenclatures AS st
ON (s.id_nomenclature_observation_status = st.id_nomenclature)
WHERE areas.type_code = 'COM'
AND ( NOT dl.cd_nomenclature = '4' OR s.id_nomenclature_diffusion_level IS NULL )
AND ( NOT sens.cd_nomenclature = '4' OR s.id_nomenclature_sensitivity IS NULL )
AND st.cd_nomenclature = 'Pr' ;
134 changes: 134 additions & 0 deletions data/update/update_synthese.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,134 @@
BEGIN;

DROP MATERIALIZED VIEW IF EXISTS synthese.vm_cor_synthese_area;

CREATE MATERIALIZED VIEW synthese.vm_cor_synthese_area
TABLESPACE pg_default
AS
SELECT DISTINCT ON (sa.id_synthese, t.type_code)
sa.id_synthese,
sa.id_area,
st_transform(a.centroid, 4326) AS centroid_4326,
t.type_code,
a.area_code
FROM synthese.cor_area_synthese AS sa
JOIN ref_geo.l_areas AS a
ON (sa.id_area = a.id_area)
JOIN ref_geo.bib_areas_types AS t
ON (a.id_type = t.id_type)
WHERE t.type_code IN ('M10', 'COM', 'DEP')
WITH DATA;

GRANT SELECT ON TABLE synthese.vm_cor_synthese_area TO geonatatlas;

-- View indexes:
CREATE UNIQUE INDEX ON synthese.vm_cor_synthese_area (id_synthese, id_area);
CREATE INDEX ON synthese.vm_cor_synthese_area (type_code);


CREATE OR REPLACE FUNCTION atlas.get_blurring_centroid_geom_by_code(code CHARACTER VARYING, idSynthese INTEGER)
RETURNS geometry
LANGUAGE plpgsql
IMMUTABLE
AS $function$
-- Function which return the centroid for a sensitivity or diffusion_level code and a synthese id
DECLARE centroid geometry;

BEGIN
SELECT INTO centroid csa.centroid_4326
FROM synthese.vm_cor_synthese_area AS csa
WHERE csa.id_synthese = idSynthese
AND csa.type_code = (CASE WHEN code = '1' THEN 'COM' WHEN code = '2' THEN 'M10' WHEN code = '3' THEN 'DEP' END)
LIMIT 1 ;

RETURN centroid ;
END;
$function$
;


DROP VIEW IF EXISTS synthese.syntheseff;


CREATE VIEW synthese.syntheseff AS
SELECT
s.id_synthese,
s.id_dataset,
s.cd_nom,
s.date_min AS dateobs,
s.observers AS observateurs,
(s.altitude_min + s.altitude_max) / 2 AS altitude_retenue,
CASE
WHEN (sens.cd_nomenclature::INT >= 1 AND sens.cd_nomenclature::INT <= 3 AND dl.cd_nomenclature::INT >= 1 AND dl.cd_nomenclature::INT <= 3) THEN
CASE
WHEN (sens.cd_nomenclature::INT >= dl.cd_nomenclature::INT) THEN (
atlas.get_blurring_centroid_geom_by_code(sens.cd_nomenclature, s.id_synthese)
)
WHEN (sens.cd_nomenclature::INT < dl.cd_nomenclature::INT) THEN (
atlas.get_blurring_centroid_geom_by_code(dl.cd_nomenclature, s.id_synthese)
)
END
WHEN (sens.cd_nomenclature::INT >= 1 AND sens.cd_nomenclature::INT <= 3) AND (dl.cd_nomenclature::INT < 1 OR dl.cd_nomenclature::INT > 3) THEN (
atlas.get_blurring_centroid_geom_by_code(sens.cd_nomenclature, s.id_synthese)
)
WHEN (dl.cd_nomenclature::INT >= 1 AND dl.cd_nomenclature::INT <= 3) AND (sens.cd_nomenclature::INT < 1 OR sens.cd_nomenclature::INT > 3) THEN (
atlas.get_blurring_centroid_geom_by_code(dl.cd_nomenclature, s.id_synthese)
)
ELSE st_transform(s.the_geom_point, 4326)
END AS the_geom_point,
s.count_min AS effectif_total,
areas.area_code AS insee,
sens.cd_nomenclature AS sensitivity,
dl.cd_nomenclature AS diffusion_level
FROM synthese.synthese s
JOIN synthese.vm_cor_synthese_area AS areas
ON (s.id_synthese = areas.id_synthese)
LEFT JOIN synthese.t_nomenclatures AS sens
ON (s.id_nomenclature_sensitivity = sens.id_nomenclature)
LEFT JOIN synthese.t_nomenclatures AS dl
ON (s.id_nomenclature_diffusion_level = dl.id_nomenclature)
LEFT JOIN synthese.t_nomenclatures AS st
ON (s.id_nomenclature_observation_status = st.id_nomenclature)
WHERE areas.type_code = 'COM'
AND ( NOT dl.cd_nomenclature = '4' OR s.id_nomenclature_diffusion_level IS NULL )
AND ( NOT sens.cd_nomenclature = '4' OR s.id_nomenclature_sensitivity IS NULL )
AND st.cd_nomenclature = 'Pr' ;


-- Rafraichissement des vues contenant les données de l'atlas
CREATE OR REPLACE FUNCTION atlas.refresh_materialized_view_data()
RETURNS VOID AS $$
BEGIN

REFRESH MATERIALIZED VIEW CONCURRENTLY synthese.vm_cor_synthese_area;

REFRESH MATERIALIZED VIEW CONCURRENTLY atlas.vm_observations;
REFRESH MATERIALIZED VIEW CONCURRENTLY atlas.vm_observations_mailles;
REFRESH MATERIALIZED VIEW CONCURRENTLY atlas.vm_mois;

REFRESH MATERIALIZED VIEW CONCURRENTLY atlas.vm_altitudes;

REFRESH MATERIALIZED VIEW CONCURRENTLY atlas.vm_taxons;
REFRESH MATERIALIZED VIEW CONCURRENTLY atlas.vm_cor_taxon_attribut;
REFRESH MATERIALIZED VIEW CONCURRENTLY atlas.vm_search_taxon;
REFRESH MATERIALIZED VIEW CONCURRENTLY atlas.vm_medias;
REFRESH MATERIALIZED VIEW CONCURRENTLY atlas.vm_taxons_plus_observes;

END
$$ LANGUAGE plpgsql;


-- TODO: ajouter au CHANGELOG la nécessité d'executer la commande SQL suivante
-- où il faut remplacer <my_reader_user> par la bonne valeur :
-- GRANT SELECT ON TABLE synthese.vm_cor_synthese_area TO <my_reader_user>;
-- Par défaut, ce script associe les droits à geonatatlas ligne 22.

-- TODO: ajouter au CHANGELOG la possiblité d'ajouter l'option FDW fetch_size
-- dans le cas des bases avec plusieurs millions d'obs dans la synthese :
-- ALTER SERVER geonaturedbserver OPTIONS (ADD fetch_size '1000000');

-- TODO: ajouter au CHANGELOG la nécessité de lancer le script : data/update/update_vm_observations.sql
-- pour prendre en compte le nouveau champ "sensitivity" de la vm_observations.
-- Ce champ n'est pas encore utilisé par l'interface...

COMMIT;
2 changes: 1 addition & 1 deletion install_db.sh
Original file line number Diff line number Diff line change
Expand Up @@ -95,7 +95,7 @@ if ! database_exists $db_name
then
echo "Adding FDW and connection to the GeoNature parent DB"
sudo -u postgres -s psql -d $db_name -c "CREATE EXTENSION IF NOT EXISTS postgres_fdw;" &>> log/install_db.log
sudo -u postgres -s psql -d $db_name -c "CREATE SERVER geonaturedbserver FOREIGN DATA WRAPPER postgres_fdw OPTIONS (host '$db_source_host', dbname '$db_source_name', port '$db_source_port');" &>> log/install_db.log
sudo -u postgres -s psql -d $db_name -c "CREATE SERVER geonaturedbserver FOREIGN DATA WRAPPER postgres_fdw OPTIONS (host '$db_source_host', dbname '$db_source_name', port '$db_source_port', fetch_size '$db_source_fetch_size');" &>> log/install_db.log
sudo -u postgres -s psql -d $db_name -c "ALTER SERVER geonaturedbserver OWNER TO $owner_atlas;" &>> log/install_db.log
sudo -u postgres -s psql -d $db_name -c "CREATE USER MAPPING FOR $owner_atlas SERVER geonaturedbserver OPTIONS (user '$atlas_source_user', password '$atlas_source_pass') ;" &>> log/install_db.log
fi
Expand Down

0 comments on commit 9f30331

Please sign in to comment.