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

Réimplémentation de la sensibilité #441

Open
wants to merge 30 commits into
base: develop
Choose a base branch
from
Open

Conversation

TheoLechemia
Copy link
Member

@TheoLechemia TheoLechemia commented Sep 22, 2022

Cette PR reprend le travail de Maxime sur la sensibilité.
La partie backend et frontend a été conservée (quelques peu modifiée), elle permet à l'API d'afficher différents niveaux de géométries dégradées sur une fiche espèce et sur les dernières obs, et au frontend de controler ces différentes couches à l'aide d'un sélecteur de couche.
Côté SQL, la PR a été complètement reprise pour se baser sur celle-ci : #358
Le calcul de la géométrie dégradée est fait de la manière suivante :

id_nomenclature_sensitivity Geom associée
0 Précise
1 Maille 1km
2 Maille 5km
3 Maille 10km
4 Pas de diffusion

On exclue volontairement les communes et les départements pour des raisons de performances.
Pour calculer les géométrie dégradées on s'appuie sur la table de la synthese de GeoNature gn_synthese.cor_area_synthese qui comprend déjà toutes les intersections avec les mailles dont nous avons besoin. l'objectif et ne refaire aucune intersection pour gagner en performance.
Une vue materialisée intermédiaire est créée en amont du calcul de la vm_observations pour améliorer les performances : atlas.vm_cor_area_synthese
Cette VM est construite à partir de gn_synthese.cor_area_synthese à laquelle on rajoute un booléen pour connaître la bonne géométrie dégradée en fonction de la sensibilité de l'observation courante.

id_synthese type_code is_blured_geom
1 M1 t
1 M5 f
1 M10 f

Calcul de VM observations :

Cette table contient uniquement des géométrie de type point (the_geom_point).
Quatre cas :

  • l'observation initiale est un point non sensible -> on prend la géom telle quelle
  • l'observation initiale est un point sensible -> on prend le centroid de la maille de dégradation
  • l'observation est un polygone non sensible -> on prend le centroid de la geom initiale
  • l'observation est un polygone sensible -> on prend le centroid des mailles de dégradation (necessite de faire un st_unions() sur les mailles)

Calcul de VM observations maille :

  • l'observation initiale est un point non sensible -> on prend la maille de taille correspondant au paramètre paramètre taillemaille
  • l'observation initiale est un point sensible -> on prend la maille de dégradation
  • l'observation est un polygone non sensible -> on prend le ou les les mailles de taille correspondant au paramètre taillemaille
  • l'observation est un polygone sensible -> on prend le ou les mailles de dégradation

Cette VM perd donc l'unicité sur le champ id_observation, une même observation pouvant être dans N mailles.

LIMITES :

  • Pour les atlas non basés sur GeoNature, et qui n'ont par conséquence pas la table gn_synthese.cor_area_synthese, l'installation est plus compliquée. Il faut se refaire les vues vm_observations et vm_observations_mailles

AVANTAGES :

  • Meilleurs perf
  • On a plus besoin d'importer les mailles car celle-ci sont déjà compris dans la vm_observations_mailles, et qu'on ne fait plus d'intersection

TODO :

  • Revoir les scripts d'installation de la BDD
  • L'intersection avec le territoire n'est plus faite. Necessaire ? Ou custo de la vm_observations ?

Lié à #117

Maxime Vergez and others added 28 commits July 26, 2021 14:04
Add layerGroups to the map for the user to be able to filter
along the different cells (Department, cities, 10km, 1km)
Added id_type to all queries to be able to filter along this
property
Correct zoom function to work on all "fiches" by adding a
zoomMaille function
Added snogylop to ficheCommune.html and invert: true in style of
map
Changed layerGroup by featureGroup to have bringToBack and
bringToFront functions
Add bringToFront and bringToBack to respectively the 1km² cell and
the department because it was impossible to click on a city cell
Changed the sql files to be able to reproduce the changes done on
the database.
Tested if it was possible to add hover and click effect to
hightlight a specific cell.
Added ZIndex values for the filter to be more robust
Beforehand the lastObservationsCommuneMaille selected from
the vm_observations which was not coherent. Now it selects from
vm_observations_mailles.
Add columns to select and removed the last_obs intermediate
Enabled to get the id of the cell and its type.
Cells border color is now grey
Made styleMailleClickedOrHover more versatile
styleMailleClickedOrHover now takes the --main-color css var to
fill the cells with the main color of the atlas
Removed setZIndex because it was useless
Added a new var (main-color-rgb) which is the same as main-color
variable but with a rgb description enabling to set different
opacity depending on the state (hover or click) of the row in
the tabEspece
Now the layers stack properly when the user activate or deactivate
them from the Control (top hand right corner).
Add a selected variable enabling the clicked cell to stay filled
even if the mouse exits the cell (mouseout event called)
Before was used to find a way to set background opacity other
than by using rgb formulation
Sql query was from vm_observations whereas we are in
a Maille function so it should be from vm_observations_maille
Corrected a copy paste mistake on id_type
Added dateobs in lastObservationsCommune
The older function took oservations based on Insee whereas it
should take info from the observations requested before. This new
function is based on the observations dictionnary that is
computed from the vm_observations (maille or not) and take the
taxons info
Used this function in atlasRoutes.py
mapHome.js: Clarified code
mapGenerator.js: Move control layer bloc for  more clarity as well
  Added id_type in property for geojson of commune
  Corrected a bug by added addTo(map) in displayMailleLayerLastObs
mapHome.js: simplified code
To be compatible with the new get_taxons_from_obs function, the
date object must be returned and not an str conversion
The function crashed when there were no taxons in a particular
city. Changed also the request for it to be more versatile in
terms of cd_ref (bugged when there was one taxon)
atlas.sql:
   add centroid to vm_observations to be compatible with point
   mode
   Changed st_contains by st_intersect as mentionned in an issue
observations_mailles.sql:
   Changed tables where to take infos
   Make this vm independant from vm_observations
   Removed index since it take to much space
atlas_synthese.sql:
   Changed index since it was not working with observations that
   do not have type_code
   Returns Point when there is no sensibility instead of a mesh
   cell
Need to update leaflet for bringToFront/BringToBack to work
Remove dependency to snogilop (had to test for compatibility)
To be able to alter the background transparency of the species
list on the main page, we need to have a rgb color. Indeed rgba()
css function does not work on hexadecimal colors. It adds complexity
but this seems to be the only way
In FicheEspece: the displayed cities were not right. There was no
instersection between the observation and the cities. Now for
instance, for a department level observation all the cities in the
department will appear...
In popup showing species, removes duplicates so that only different
species are displayed
Changed the plain id number to a Select with a Like to enter
directly the mesh cell type
It might be a parameter in the settings.ini in the future
Comment on lines +27 to +33
CASE
WHEN sensi.cd_nomenclature::text = '1'::text AND t.type_code::text = 'M1'::text THEN true
WHEN sensi.cd_nomenclature::text = '2'::text AND t.type_code::text = 'M5'::text THEN true
WHEN sensi.cd_nomenclature::text = '3'::text AND t.type_code::text = 'M10'::text THEN true
WHEN (sensi.cd_nomenclature::text = '0'::TEXT OR sensi.cd_nomenclature::text IS NULL) AND t.type_code::text = :default_maille::text THEN true
ELSE false
END AS is_blurred_geom
Copy link
Contributor

Choose a reason for hiding this comment

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

Une suggestion, en mettant ce code SQL dans une fonction cela permettrait de facilement pouvoir changer la correspondance valeur de sensibilité et maille à utiliser.

Copy link
Member

Choose a reason for hiding this comment

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

Je pense que c'est géré ou devrait être géré au niveau de la BDD source (GeoNature dans une majorité des cas), pas au niveau de GeoNature-atlas.

Copy link
Contributor

Choose a reason for hiding this comment

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

Je pense que c'est géré ou devrait être géré au niveau de la BDD source (GeoNature dans une majorité des cas), pas au niveau de GeoNature-atlas.

Oui, idéalement. Mais avec l'utilisation de table via Foreign Data Wrapper, je ne sais pas si on peut utiliser des fonctions de la base de données source.

Choose a reason for hiding this comment

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

Si plutôt qu'une fonction nous mettions un paramètre dans la config ?
Qu'en pensez-vous ?

Copy link
Contributor

@jpm-cbna jpm-cbna Nov 5, 2024

Choose a reason for hiding this comment

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

Si plutôt qu'une fonction nous mettions un paramètre dans la config ? Qu'en pensez-vous ?

Le paramètre serait utilisé pour générer le code SQL lors de l'installation ? Mais dans ce cas là, une modification du paramètre dans le fichier de config, après installation de la base de données, ne changerait rien dans la base.

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
LEFT JOIN synthese.t_nomenclatures sensi ON s.id_nomenclature_sensitivity = sensi.id_nomenclature
WHERE (t.type_code::text = ANY (ARRAY['M1'::character varying, 'M5'::character varying, 'M10'::character varying]::text[]))
Copy link
Contributor

Choose a reason for hiding this comment

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

Ici, aussi, il serait peut être nécessaire d'utiliser une fonction pour pouvoir personnaliser les zones à utiliser.

FROM synthese.synthese s
JOIN atlas.vm_taxref tx ON tx.cd_nom = s.cd_nom
LEFT JOIN synthese.t_nomenclatures sensi ON s.id_nomenclature_sensitivity = sensi.id_nomenclature
JOIN centroid c ON c.id_synthese = s.id_synthese
Copy link
Contributor

@jpm-cbna jpm-cbna Sep 25, 2024

Choose a reason for hiding this comment

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

La sous-requête "centroid", ne récupérant que les observations où is_blurred_geom vaut true, est ce que l'on ne va pas récupérer ici avec cette jointure que les observations floutées ?

Copy link
Contributor

Choose a reason for hiding this comment

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

J'ai compris finalement que les mailles utilisées par défaut lorsqu'on force l'Atlas à afficher uniquement des mailles sont aussi comprises dans is_blurred_geom = true... Donc, normalement, toutes les observations sont prises en compte.

JOIN atlas.vm_taxref tx ON tx.cd_nom = s.cd_nom
LEFT JOIN synthese.t_nomenclatures sensi ON s.id_nomenclature_sensitivity = sensi.id_nomenclature
JOIN centroid c ON c.id_synthese = s.id_synthese
JOIN atlas.l_communes com ON st_intersects(st_transform(s.the_geom_point, 3857), com.the_geom)
Copy link
Contributor

Choose a reason for hiding this comment

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

Afin d'associer les observations à flouter à la commune correspondant au centroïde de la géométrie de l'observations, il me semble que le st_intersect() devrait se faire sur le champ c.geom_point.

@jpm-cbna
Copy link
Contributor

jpm-cbna commented Sep 27, 2024

Si cela peut servir, voici le code SQL que je vais surement utiliser avec les nouvelles nomenclatures sensibilités. Il y a encore dedans la notion de niveau de diffusion pour des raisons de compatibilité avec l'existant mais cela devrait disparaître à terme.

Il me semble également que l'on pourrait simplifier la VM vm_cor_synthese_area en faisant en sorte qu'elle ne contiennent que les mailles pour les observations sensibles. C'est ce que j'ai fait au final. Mais dans le cadre de cette PR ce n'est peut être pas possible.

Le code SQL ci-dessous et le lien vers le commit final (16cdbe1):

-- Fonctions

CREATE OR REPLACE FUNCTION atlas.is_blurred_area_type_by_diffusion_level(
  nomenclatureCode CHARACTER VARYING,
  areaTypeCode CHARACTER VARYING
)
RETURNS boolean
LANGUAGE plpgsql
IMMUTABLE
AS $function$
  DECLARE isBlurred boolean;

  BEGIN
    SELECT INTO isBlurred
      CASE
        WHEN ( nomenclatureCode = '0' AND areaTypeCode = 'M5' ) THEN true
        WHEN ( nomenclatureCode = '1' AND areaTypeCode = 'M5' ) THEN true
        WHEN ( nomenclatureCode = '2' AND areaTypeCode = 'M5' ) THEN true
        WHEN ( nomenclatureCode = '3' AND areaTypeCode = 'M5' ) THEN true
        ELSE false
      END ;

    RETURN isBlurred ;
  END;
$function$
;

CREATE OR REPLACE FUNCTION atlas.is_blurred_area_type_by_sensitivity(
  nomenclatureCode CHARACTER VARYING,
  areaTypeCode CHARACTER VARYING
)
RETURNS boolean
LANGUAGE plpgsql
IMMUTABLE
AS $function$
  DECLARE isBlurred boolean;

  BEGIN
    SELECT INTO isBlurred
      CASE
        WHEN ( nomenclatureCode = '1' AND areaTypeCode = 'M5' ) THEN true
        WHEN ( nomenclatureCode = '2' AND areaTypeCode = 'M5' ) THEN true
        WHEN ( nomenclatureCode = '3' AND areaTypeCode = 'M5' ) THEN true
        WHEN ( nomenclatureCode = '2.1' AND areaTypeCode = 'M1' ) THEN true
        WHEN ( nomenclatureCode = '2.2' AND areaTypeCode = 'M2' ) THEN true
        WHEN ( nomenclatureCode = '2.3' AND areaTypeCode = 'M5' ) THEN true
        WHEN ( nomenclatureCode = '2.4' AND areaTypeCode = 'M10' ) THEN true
        WHEN ( nomenclatureCode = '2.5' AND areaTypeCode = 'M20' ) THEN true
        WHEN ( nomenclatureCode = '2.6' AND areaTypeCode = 'M50' ) THEN true
        WHEN ( nomenclatureCode = '2.7' AND areaTypeCode = 'M50' ) THEN true
        ELSE false
      END ;

    RETURN isBlurred ;
  END;
$function$
;

CREATE OR REPLACE FUNCTION atlas.is_default_mesh(
  areaTypeCode CHARACTER VARYING
)
RETURNS boolean
LANGUAGE plpgsql
IMMUTABLE
AS $function$
  DECLARE isBlurred boolean;

  BEGIN
    SELECT INTO isBlurred
      CASE
        WHEN ( areaTypeCode = 'M5' ) THEN true
        ELSE false
      END ;

    RETURN isBlurred ;
  END;
$function$
;

CREATE OR REPLACE FUNCTION atlas.is_blurred_area_type(
  sensiCode CHARACTER VARYING,
  diffusionCode CHARACTER VARYING,
  areaTypeCode CHARACTER VARYING
)
RETURNS boolean
LANGUAGE plpgsql
IMMUTABLE
AS $function$
  DECLARE isBlurred boolean;

  BEGIN
    SELECT INTO isBlurred
      CASE
        WHEN (sensiCode::INT >= 1 AND sensiCode::INT <= 3 AND diffusionCode::INT >= 0 AND diffusionCode::INT <= 3) THEN
        CASE
            WHEN (sensiCode::INT >= diffusionCode::INT) THEN (
              atlas.is_blurred_area_type_by_sensitivity(sensiCode, areaTypeCode)
            )
            WHEN (sensiCode::INT < diffusionCode::INT) THEN (
              atlas.is_blurred_area_type_by_diffusion_level(diffusionCode, areaTypeCode)
            )
          END
        WHEN (sensiCode::INT >= 1 AND sensiCode::INT <= 3) AND (diffusionCode::INT > 4) THEN (
          atlas.is_blurred_area_type_by_sensitivity(sensiCode, areaTypeCode)
        )
        WHEN (diffusionCode::INT >= 0 AND diffusionCode::INT <= 3) AND (sensiCode::INT < 1) THEN (
          atlas.is_blurred_area_type_by_diffusion_level(diffusionCode, areaTypeCode)
        )
        ELSE false
      END;

    RETURN isBlurred ;
  END;
$function$
;

-- Toutes les correspondances observations à flouter et zones géographiques

CREATE MATERIALIZED VIEW atlas.vm_cor_synthese_area
TABLESPACE pg_default
AS
  SELECT
    sa.id_synthese,
    sa.id_area,
    st_transform(a.geom, 4326) AS geom_4326,
    st_transform(a.centroid, 4326) AS centroid_4326,
    t.type_code,
    a.area_code,
    atlas.is_blurred_area_type(
      sens.cd_nomenclature,
      dl.cd_nomenclature,
      t.type_code
    ) AS is_blurred,
    atlas.is_default_mesh(
      t.type_code
    ) AS is_default_mesh,
    sens.cd_nomenclature AS sensitivity, -- DEBUG : DELETE THIS
    dl.cd_nomenclature AS diffusion_level -- DEBUG : DELETE THIS
  FROM synthese.synthese AS s
    JOIN synthese.cor_area_synthese AS sa
      ON (s.id_synthese = sa.id_synthese)
    JOIN synthese.t_nomenclatures AS sens
      ON (s.id_nomenclature_sensitivity = sens.id_nomenclature)
    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)
    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 st.cd_nomenclature = 'Pr'
    AND dl.cd_nomenclature != '4'
    AND sens.cd_nomenclature NOT IN ('4', '2.8')
    AND t.type_code IN ('M1', 'M2', 'M5', 'M10', 'M20', 'M50')
WITH DATA;

CREATE UNIQUE INDEX i_vm_cor_synthese_area ON atlas.vm_cor_synthese_area USING btree (id_synthese, id_area);
CREATE INDEX ON atlas.vm_cor_synthese_area (type_code);


-- Toutes les observations

--DROP materialized view atlas.vm_observations;
CREATE MATERIALIZED VIEW atlas.vm_observations AS
WITH blurred_centroid AS (
  SELECT
    csa.id_synthese,
    st_centroid(st_union(csa.geom_4326)) AS geom_point
  FROM atlas.vm_cor_synthese_area3 AS csa
  WHERE csa.is_blurred IS TRUE
  GROUP BY csa.id_synthese
),
blurred_centroid_insee AS (
  SELECT
    bc.id_synthese,
    bc.geom_point,
      com.insee
  FROM blurred_centroid AS bc
      LEFT JOIN atlas.l_communes AS com
        ON (st_intersects(bc.geom_point, com.the_geom))
)
SELECT
  s.id_synthese AS id_observation,
  COALESCE(
    bci.insee,
    (SELECT insee FROM atlas.l_communes WHERE st_intersects(s.the_geom_point, the_geom) = TRUE)
  ) AS insee,
  s.date_min AS dateobs,
  s.observers AS observateurs,
  (s.altitude_min + s.altitude_max) / 2 AS altitude_retenue,
  CASE
    WHEN bci.geom_point IS NOT NULL THEN bci.geom_point
    ELSE s.the_geom_point
  END AS the_geom_point,
  s.count_min AS effectif_total,
  tx.cd_ref,
  CASE
    WHEN bci.geom_point IS NOT NULL THEN st_asgeojson(bci.geom_point)
    ELSE st_asgeojson(s.the_geom_point)
  END AS geojson_point,
  sens.cd_nomenclature AS sensitivity,
  dl.cd_nomenclature AS diffusion_level,
  s.id_dataset
FROM synthese.synthese AS s
  JOIN atlas.vm_taxref AS tx
    ON tx.cd_nom = s.cd_nom
  JOIN synthese.t_nomenclatures AS sens
    ON (s.id_nomenclature_sensitivity = sens.id_nomenclature)
  JOIN synthese.t_nomenclatures AS dl
    ON (s.id_nomenclature_diffusion_level = dl.id_nomenclature)
  JOIN synthese.t_nomenclatures AS st
      ON (s.id_nomenclature_observation_status = st.id_nomenclature)
  LEFT JOIN blurred_centroid_insee AS bci
    ON bci.id_synthese = s.id_synthese
WHERE st.cd_nomenclature = 'Pr'
  AND dl.cd_nomenclature != '4'
  AND sens.cd_nomenclature NOT IN ('4', '2.8') ;

CREATE UNIQUE INDEX ON atlas.vm_observations (id_observation);
CREATE INDEX ON atlas.vm_observations (cd_ref);
CREATE INDEX ON atlas.vm_observations (insee);
CREATE INDEX ON atlas.vm_observations (altitude_retenue);
CREATE INDEX ON atlas.vm_observations (dateobs);
CREATE INDEX index_gist_vm_observations_the_geom_point ON atlas.vm_observations USING gist (the_geom_point);

Sign up for free to join this conversation on GitHub. Already have an account? Sign in to comment
Labels
None yet
Projects
None yet
Development

Successfully merging this pull request may close these issues.

4 participants