diff --git a/backend/gn_module_zh/blueprint.py b/backend/gn_module_zh/blueprint.py index 57b20e21..28bfd11c 100644 --- a/backend/gn_module_zh/blueprint.py +++ b/backend/gn_module_zh/blueprint.py @@ -27,6 +27,7 @@ from utils_flask_sqla.response import json_resp_accept_empty_list, json_resp from .api_error import ZHApiError +from . import tasks # noqa: F401 from .forms import ( create_zh, post_file_info, @@ -81,6 +82,7 @@ get_main_picture_id, get_user_cruved, ) +import gn_module_zh.tasks blueprint = Blueprint("pr_zh", __name__, "./static", template_folder="templates") @@ -810,8 +812,9 @@ def write_csv(id_zh): tableName=blueprint.config[i]["table_name"], schemaName=blueprint.config[i]["schema_name"], filters={"id_zh": id_zh, "orderby": "id_zh"}, - limit=100, + # TODO: limit=-1 when version 0.4.2 of Utils-Flask-SQLAlchemy will be released ) + results = query.return_query().get("items", []) current_date = dt.now() if results: diff --git a/backend/gn_module_zh/conf_schema_toml.py b/backend/gn_module_zh/conf_schema_toml.py index b99b5e7c..4bbb4321 100644 --- a/backend/gn_module_zh/conf_schema_toml.py +++ b/backend/gn_module_zh/conf_schema_toml.py @@ -103,17 +103,17 @@ class MapListConfig(Schema): vertebrates_view_name = { "schema_name": "pr_zh", - "table_name": "vertebrates", + "table_name": "vm_vertebrates", "category": "vertebrates", } invertebrates_view_name = { "schema_name": "pr_zh", - "table_name": "invertebrates", + "table_name": "vm_invertebrates", "category": "invertebrates", } -flora_view_name = {"schema_name": "pr_zh", "table_name": "flora", "category": "flora"} +flora_view_name = {"schema_name": "pr_zh", "table_name": "vm_flora", "category": "flora"} # Name of the source of species data (tab5) species_source_name = "GeoNature" @@ -178,3 +178,4 @@ class GnModuleSchemaConf(Schema): pdf_small_layer_number = fields.Integer(load_default=pdf_small_layer_number) pdf_last_page_img = fields.String(load_default=pdf_last_page_img) pdf_title = fields.String(load_default=pdf_title) + TAXON_VM_CRONTAB = fields.String(load_default="0 0,12 * * *") diff --git a/backend/gn_module_zh/hierarchy.py b/backend/gn_module_zh/hierarchy.py index d1a0de7a..70b670ed 100644 --- a/backend/gn_module_zh/hierarchy.py +++ b/backend/gn_module_zh/hierarchy.py @@ -1180,6 +1180,7 @@ def __check_if_rules(self): raise ZHApiError( message="no_rb_rules", details="no existing rules for the river basin", + status_code=400, ) except ZHApiError: raise @@ -1235,7 +1236,6 @@ def get_all_hierarchy_fields(id_rb: int): tableName="all_rb_rules", schemaName="pr_zh", filters={"id_rb": id_rb, "orderby": "name"}, - limit=100000, ) results = query.return_query() diff --git a/backend/gn_module_zh/migrations/76e89c793961_create_vm_taxon_refresh_function.py b/backend/gn_module_zh/migrations/76e89c793961_create_vm_taxon_refresh_function.py new file mode 100644 index 00000000..a89e6194 --- /dev/null +++ b/backend/gn_module_zh/migrations/76e89c793961_create_vm_taxon_refresh_function.py @@ -0,0 +1,43 @@ +"""create_vm_taxon_refresh_function + +Revision ID: 76e89c793961 +Revises: c0c4748a597a +Create Date: 2024-04-16 08:12:41.346540 + +""" + +from alembic import op +import sqlalchemy as sa + + +# revision identifiers, used by Alembic. +revision = "76e89c793961" +down_revision = "c0c4748a597a" +branch_labels = None +depends_on = None + + +def upgrade(): + op.execute( + """ + CREATE OR REPLACE FUNCTION pr_zh.refresh_taxon_materialized_views() + RETURNS void + LANGUAGE plpgsql + AS $function$ + BEGIN + REFRESH MATERIALIZED VIEW pr_zh.vm_vertebrates; + REFRESH MATERIALIZED VIEW pr_zh.vm_invertebrates; + REFRESH MATERIALIZED VIEW pr_zh.vm_flora; + END; + $function$ + ; + """ + ) + + +def downgrade(): + op.execute( + """ + DROP FUNCTION pr_zh.refresh_taxon_materialized_views(); + """ + ) diff --git a/backend/gn_module_zh/migrations/c0c4748a597a_create_vm_taxons.py b/backend/gn_module_zh/migrations/c0c4748a597a_create_vm_taxons.py new file mode 100644 index 00000000..ac1e3df2 --- /dev/null +++ b/backend/gn_module_zh/migrations/c0c4748a597a_create_vm_taxons.py @@ -0,0 +1,597 @@ +"""create_vm_taxons + +Revision ID: c0c4748a597a +Revises: 510677623a13 +Create Date: 2024-04-09 15:30:20.522477 + +""" + +from alembic import op +import sqlalchemy as sa + + +# revision identifiers, used by Alembic. +revision = "c0c4748a597a" +down_revision = "510677623a13" +branch_labels = None +depends_on = None + + +def upgrade(): + op.execute( + """ + DROP VIEW IF EXISTS pr_zh.vertebrates; + DROP VIEW IF EXISTS pr_zh.invertebrates; + DROP VIEW IF EXISTS pr_zh.flora; + + CREATE MATERIALIZED VIEW pr_zh.vm_vertebrates AS + WITH + synthese_taxa AS ( + SELECT + synthese.id_synthese, + ( + SELECT t_zh.id_zh + FROM pr_zh.t_zh + WHERE st_intersects(st_setsrid(t_zh.geom, 4326), st_setsrid(synthese.the_geom_point, 4326)) + ) AS id_zh, + synthese.cd_nom, + synthese.date_max, + synthese.observers, + ( + SELECT organisme + FROM utilisateurs.v_userslist_forall_applications + WHERE nom_role || ' ' || prenom_role = synthese.observers limit 1 + ) + FROM gn_synthese.synthese + ), + synthese_zh AS ( + SELECT DISTINCT ON (id_zh, cd_nom) * + FROM synthese_taxa + WHERE id_zh IS NOT null + ORDER BY id_zh, cd_nom, date_max DESC + ), + bdc_statut AS ( + SELECT + cd_nom, + cd_sig, + regroupement_type AS statut_type, + lb_type_statut || ' - ' || label_statut AS statut, + full_citation AS article, + doc_url AS doc_url + FROM taxonomie.bdc_statut + WHERE ( + regroupement_type = 'Liste rouge' + AND code_statut IN ('VU', 'EN', 'CR') + ) + OR ( + regroupement_type IN ('ZNIEFF', 'Réglementation', 'Protection', 'Directives européennes') + ) + ) + + SELECT + synthese_zh.id_zh, + taxref.cd_nom, + taxref.classe AS group_class, + taxref.ordre AS group_order, + taxref.nom_complet AS scientific_name, + taxref.nom_vern AS vernac_name, + bdc_statut.statut_type AS statut_type, + bdc_statut.statut AS statut, + bdc_statut.article AS article, + bdc_statut.doc_url AS doc_url, + synthese_zh.date_max AS last_date, + synthese_zh.observers AS observer, + synthese_zh.organisme AS organisme, + (select count(cd_nom) from synthese_taxa where id_zh = synthese_zh.id_zh and cd_nom = taxref.cd_nom)::integer AS obs_nb + FROM synthese_zh + LEFT JOIN taxonomie.taxref taxref ON synthese_zh.cd_nom = taxref.cd_nom + LEFT JOIN bdc_statut ON bdc_statut.cd_nom = taxref.cd_nom + WHERE synthese_zh.id_zh IS NOT NULL + AND (synthese_zh.date_max::timestamp > (NOW()::timestamp - interval '20 years')) + AND taxref.phylum = 'Chordata' + AND ( + bdc_statut.cd_sig = 'ETATFRA' + OR bdc_statut.cd_sig IN + ( + SELECT + DISTINCT('INSEER' || lim.insee_reg) AS cd_sig + FROM pr_zh.t_zh tzh + LEFT JOIN pr_zh.cor_zh_area cza ON cza.id_zh = tzh.id_zh + LEFT JOIN ref_geo.l_areas lareas ON cza.id_area = lareas.id_area + LEFT JOIN ref_geo.li_municipalities lim ON lim.id_area = lareas.id_area + WHERE tzh.id_zh = synthese_zh.id_zh + AND lim.insee_reg IS NOT NULL + ) + OR bdc_statut.cd_sig IN + ( + SELECT + DISTINCT('INSEED' || lareas.area_code) AS cd_sig + FROM pr_zh.t_zh tzh + LEFT JOIN pr_zh.cor_zh_area cza ON cza.id_zh = tzh.id_zh + LEFT JOIN ref_geo.l_areas lareas ON cza.id_area = lareas.id_area + WHERE tzh.id_zh = synthese_zh.id_zh + AND id_type = (SELECT id_type FROM ref_geo.bib_areas_types WHERE type_code = 'DEP') + AND lareas.area_code IS NOT NULL + ) + OR (bdc_statut.statut_type in ('Liste rouge', 'Réglementation', 'Protection', 'Directives européennes') and bdc_statut.cd_sig = 'TERFXFR') + ) + GROUP BY taxref.nom_complet, taxref.nom_vern, taxref.classe, synthese_zh.id_zh, taxref.cd_nom, bdc_statut.statut_type, bdc_statut.article, bdc_statut.statut, bdc_statut.doc_url, synthese_zh.date_max, synthese_zh.observers, synthese_zh.organisme; + + CREATE MATERIALIZED VIEW pr_zh.vm_invertebrates AS + WITH + synthese_taxa AS ( + SELECT + synthese.id_synthese, + ( + SELECT t_zh.id_zh + FROM pr_zh.t_zh + WHERE st_intersects(st_setsrid(t_zh.geom, 4326), st_setsrid(synthese.the_geom_point, 4326)) + ) AS id_zh, + synthese.cd_nom, + synthese.date_max, + synthese.observers, + ( + SELECT organisme + FROM utilisateurs.v_userslist_forall_applications + WHERE nom_role || ' ' || prenom_role = synthese.observers limit 1 + ) + FROM gn_synthese.synthese + ), + synthese_zh AS ( + SELECT DISTINCT ON (id_zh, cd_nom) * + FROM synthese_taxa + WHERE id_zh IS NOT null + ORDER BY id_zh, cd_nom, date_max DESC + ), + bdc_statut AS ( + SELECT + cd_nom, + cd_sig, + regroupement_type AS statut_type, + lb_type_statut || ' - ' || label_statut AS statut, + full_citation AS article, + doc_url AS doc_url + FROM taxonomie.bdc_statut + WHERE ( + regroupement_type = 'Liste rouge' + AND code_statut IN ('VU', 'EN', 'CR') + ) + OR ( + regroupement_type IN ('ZNIEFF', 'Réglementation', 'Protection', 'Directives européennes') + ) + ) + + SELECT + synthese_zh.id_zh, + taxref.cd_nom, + taxref.classe AS group_class, + taxref.ordre AS group_order, + taxref.nom_complet AS scientific_name, + taxref.nom_vern AS vernac_name, + bdc_statut.statut_type AS statut_type, + bdc_statut.statut AS statut, + bdc_statut.article AS article, + bdc_statut.doc_url AS doc_url, + synthese_zh.date_max AS last_date, + synthese_zh.observers AS observer, + synthese_zh.organisme AS organisme, + (select count(cd_nom) from synthese_taxa where id_zh = synthese_zh.id_zh and cd_nom = taxref.cd_nom)::integer AS obs_nb + FROM synthese_zh + LEFT JOIN taxonomie.taxref taxref ON synthese_zh.cd_nom = taxref.cd_nom + LEFT JOIN bdc_statut ON bdc_statut.cd_nom = taxref.cd_nom + WHERE synthese_zh.id_zh IS NOT NULL + AND (synthese_zh.date_max::timestamp > (NOW()::timestamp - interval '20 years')) + AND taxref.phylum != 'Chordata' + AND taxref.regne = 'Animalia' + AND ( + bdc_statut.cd_sig = 'ETATFRA' + OR bdc_statut.cd_sig IN + ( + SELECT + DISTINCT('INSEER' || lim.insee_reg) AS cd_sig + FROM pr_zh.t_zh tzh + LEFT JOIN pr_zh.cor_zh_area cza ON cza.id_zh = tzh.id_zh + LEFT JOIN ref_geo.l_areas lareas ON cza.id_area = lareas.id_area + LEFT JOIN ref_geo.li_municipalities lim ON lim.id_area = lareas.id_area + WHERE tzh.id_zh = synthese_zh.id_zh + AND lim.insee_reg IS NOT NULL + ) + OR bdc_statut.cd_sig IN + ( + SELECT + DISTINCT('INSEED' || lareas.area_code) AS cd_sig + FROM pr_zh.t_zh tzh + LEFT JOIN pr_zh.cor_zh_area cza ON cza.id_zh = tzh.id_zh + LEFT JOIN ref_geo.l_areas lareas ON cza.id_area = lareas.id_area + WHERE tzh.id_zh = synthese_zh.id_zh + AND id_type = (SELECT id_type FROM ref_geo.bib_areas_types WHERE type_code = 'DEP') + AND lareas.area_code IS NOT NULL + ) + OR (bdc_statut.statut_type in ('Liste rouge', 'Réglementation', 'Protection', 'Directives européennes') and bdc_statut.cd_sig = 'TERFXFR') + ) + GROUP BY taxref.nom_complet, taxref.nom_vern, taxref.classe, synthese_zh.id_zh, taxref.cd_nom, bdc_statut.statut_type, bdc_statut.article, bdc_statut.statut, bdc_statut.doc_url, synthese_zh.date_max, synthese_zh.observers, synthese_zh.organisme; + + CREATE MATERIALIZED VIEW pr_zh.vm_flora AS + WITH + synthese_taxa AS ( + SELECT + synthese.id_synthese, + ( + SELECT t_zh.id_zh + FROM pr_zh.t_zh + WHERE st_intersects(st_setsrid(t_zh.geom, 4326), st_setsrid(synthese.the_geom_point, 4326)) + ) AS id_zh, + synthese.cd_nom, + synthese.date_max, + synthese.observers, + ( + SELECT organisme + FROM utilisateurs.v_userslist_forall_applications + WHERE nom_role || ' ' || prenom_role = synthese.observers limit 1 + ) + FROM gn_synthese.synthese + ), + synthese_zh AS ( + SELECT DISTINCT ON (id_zh, cd_nom) * + FROM synthese_taxa + WHERE id_zh IS NOT null + ORDER BY id_zh, cd_nom, date_max DESC + ), + bdc_statut AS ( + SELECT + cd_nom, + cd_sig, + regroupement_type AS statut_type, + lb_type_statut || ' - ' || label_statut AS statut, + full_citation AS article, + doc_url AS doc_url + FROM taxonomie.bdc_statut + WHERE ( + regroupement_type = 'Liste rouge' + AND code_statut IN ('VU', 'EN', 'CR') + ) + OR ( + regroupement_type IN ('ZNIEFF', 'Réglementation', 'Protection', 'Directives européennes') + ) + ) + + SELECT + synthese_zh.id_zh, + taxref.cd_nom, + taxref.classe AS group_class, + taxref.ordre AS group_order, + taxref.nom_complet AS scientific_name, + taxref.nom_vern AS vernac_name, + bdc_statut.statut_type AS statut_type, + bdc_statut.statut AS statut, + bdc_statut.article AS article, + bdc_statut.doc_url AS doc_url, + synthese_zh.date_max AS last_date, + synthese_zh.observers AS observer, + synthese_zh.organisme AS organisme, + (select count(cd_nom) from synthese_taxa where id_zh = synthese_zh.id_zh and cd_nom = taxref.cd_nom)::integer AS obs_nb + FROM synthese_zh + LEFT JOIN taxonomie.taxref taxref ON synthese_zh.cd_nom = taxref.cd_nom + LEFT JOIN bdc_statut ON bdc_statut.cd_nom = taxref.cd_nom + WHERE synthese_zh.id_zh IS NOT NULL + AND (synthese_zh.date_max::timestamp > (NOW()::timestamp - interval '20 years')) + AND taxref.regne = 'Plantae' + AND ( + bdc_statut.cd_sig = 'ETATFRA' + OR bdc_statut.cd_sig IN + ( + SELECT + DISTINCT('INSEER' || lim.insee_reg) AS cd_sig + FROM pr_zh.t_zh tzh + LEFT JOIN pr_zh.cor_zh_area cza ON cza.id_zh = tzh.id_zh + LEFT JOIN ref_geo.l_areas lareas ON cza.id_area = lareas.id_area + LEFT JOIN ref_geo.li_municipalities lim ON lim.id_area = lareas.id_area + WHERE tzh.id_zh = synthese_zh.id_zh + AND lim.insee_reg IS NOT NULL + ) + OR bdc_statut.cd_sig IN + ( + SELECT + DISTINCT('INSEED' || lareas.area_code) AS cd_sig + FROM pr_zh.t_zh tzh + LEFT JOIN pr_zh.cor_zh_area cza ON cza.id_zh = tzh.id_zh + LEFT JOIN ref_geo.l_areas lareas ON cza.id_area = lareas.id_area + WHERE tzh.id_zh = synthese_zh.id_zh + AND id_type = (SELECT id_type FROM ref_geo.bib_areas_types WHERE type_code = 'DEP') + AND lareas.area_code IS NOT NULL + ) + OR (bdc_statut.statut_type in ('Liste rouge', 'Réglementation', 'Protection', 'Directives européennes') and bdc_statut.cd_sig = 'TERFXFR') + ) + GROUP BY taxref.nom_complet, taxref.nom_vern, taxref.classe, synthese_zh.id_zh, taxref.cd_nom, bdc_statut.statut_type, bdc_statut.article, bdc_statut.statut, bdc_statut.doc_url, synthese_zh.date_max, synthese_zh.observers, synthese_zh.organisme; + """ + ) + + +def downgrade(): + op.execute( + """ + DROP MATERIALIZED VIEW pr_zh.vm_vertebrates; + DROP MATERIALIZED VIEW pr_zh.vm_invertebrates; + DROP MATERIALIZED VIEW pr_zh.vm_flora; + + CREATE OR REPLACE VIEW pr_zh.vertebrates AS + WITH + synthese_taxa AS ( + SELECT + synthese.id_synthese, + ( + SELECT t_zh.id_zh + FROM pr_zh.t_zh + WHERE st_intersects(st_setsrid(t_zh.geom, 4326), st_setsrid(synthese.the_geom_point, 4326)) + ) AS id_zh, + synthese.cd_nom, + synthese.date_max, + synthese.observers, + ( + SELECT organisme + FROM utilisateurs.v_userslist_forall_applications + WHERE nom_role || ' ' || prenom_role = synthese.observers limit 1 + ) + FROM gn_synthese.synthese + ), + synthese_zh AS ( + SELECT DISTINCT ON (id_zh, cd_nom) * + FROM synthese_taxa + WHERE id_zh IS NOT null + ORDER BY id_zh, cd_nom, date_max DESC + ), + bdc_statut AS ( + SELECT + cd_nom, + cd_sig, + regroupement_type AS statut_type, + lb_type_statut || ' - ' || label_statut AS statut, + full_citation AS article, + doc_url AS doc_url + FROM taxonomie.bdc_statut + WHERE ( + regroupement_type = 'Liste rouge' + AND code_statut IN ('VU', 'EN', 'CR') + ) + OR ( + regroupement_type IN ('ZNIEFF', 'Réglementation', 'Protection', 'Directives européennes') + ) + ) + + SELECT + synthese_zh.id_zh, + taxref.cd_nom, + taxref.classe AS group_class, + taxref.ordre AS group_order, + taxref.nom_complet AS scientific_name, + taxref.nom_vern AS vernac_name, + bdc_statut.statut_type AS statut_type, + bdc_statut.statut AS statut, + bdc_statut.article AS article, + bdc_statut.doc_url AS doc_url, + synthese_zh.date_max AS last_date, + synthese_zh.observers AS observer, + synthese_zh.organisme AS organisme, + (select count(cd_nom) from synthese_taxa where id_zh = synthese_zh.id_zh and cd_nom = taxref.cd_nom)::integer AS obs_nb + FROM synthese_zh + LEFT JOIN taxonomie.taxref taxref ON synthese_zh.cd_nom = taxref.cd_nom + LEFT JOIN bdc_statut ON bdc_statut.cd_nom = taxref.cd_nom + WHERE synthese_zh.id_zh IS NOT NULL + AND (synthese_zh.date_max::timestamp > (NOW()::timestamp - interval '20 years')) + AND taxref.phylum = 'Chordata' + AND ( + bdc_statut.cd_sig = 'ETATFRA' + OR bdc_statut.cd_sig IN + ( + SELECT + DISTINCT('INSEER' || lim.insee_reg) AS cd_sig + FROM pr_zh.t_zh tzh + LEFT JOIN pr_zh.cor_zh_area cza ON cza.id_zh = tzh.id_zh + LEFT JOIN ref_geo.l_areas lareas ON cza.id_area = lareas.id_area + LEFT JOIN ref_geo.li_municipalities lim ON lim.id_area = lareas.id_area + WHERE tzh.id_zh = synthese_zh.id_zh + AND lim.insee_reg IS NOT NULL + ) + OR bdc_statut.cd_sig IN + ( + SELECT + DISTINCT('INSEED' || lareas.area_code) AS cd_sig + FROM pr_zh.t_zh tzh + LEFT JOIN pr_zh.cor_zh_area cza ON cza.id_zh = tzh.id_zh + LEFT JOIN ref_geo.l_areas lareas ON cza.id_area = lareas.id_area + WHERE tzh.id_zh = synthese_zh.id_zh + AND id_type = (SELECT id_type FROM ref_geo.bib_areas_types WHERE type_code = 'DEP') + AND lareas.area_code IS NOT NULL + ) + OR (bdc_statut.statut_type in ('Liste rouge', 'Réglementation', 'Protection', 'Directives européennes') and bdc_statut.cd_sig = 'TERFXFR') + ) + GROUP BY taxref.nom_complet, taxref.nom_vern, taxref.classe, synthese_zh.id_zh, taxref.cd_nom, bdc_statut.statut_type, bdc_statut.article, bdc_statut.statut, bdc_statut.doc_url, synthese_zh.date_max, synthese_zh.observers, synthese_zh.organisme; + + CREATE OR REPLACE VIEW pr_zh.invertebrates AS + WITH + synthese_taxa AS ( + SELECT + synthese.id_synthese, + ( + SELECT t_zh.id_zh + FROM pr_zh.t_zh + WHERE st_intersects(st_setsrid(t_zh.geom, 4326), st_setsrid(synthese.the_geom_point, 4326)) + ) AS id_zh, + synthese.cd_nom, + synthese.date_max, + synthese.observers, + ( + SELECT organisme + FROM utilisateurs.v_userslist_forall_applications + WHERE nom_role || ' ' || prenom_role = synthese.observers limit 1 + ) + FROM gn_synthese.synthese + ), + synthese_zh AS ( + SELECT DISTINCT ON (id_zh, cd_nom) * + FROM synthese_taxa + WHERE id_zh IS NOT null + ORDER BY id_zh, cd_nom, date_max DESC + ), + bdc_statut AS ( + SELECT + cd_nom, + cd_sig, + regroupement_type AS statut_type, + lb_type_statut || ' - ' || label_statut AS statut, + full_citation AS article, + doc_url AS doc_url + FROM taxonomie.bdc_statut + WHERE ( + regroupement_type = 'Liste rouge' + AND code_statut IN ('VU', 'EN', 'CR') + ) + OR ( + regroupement_type IN ('ZNIEFF', 'Réglementation', 'Protection', 'Directives européennes') + ) + ) + + SELECT + synthese_zh.id_zh, + taxref.cd_nom, + taxref.classe AS group_class, + taxref.ordre AS group_order, + taxref.nom_complet AS scientific_name, + taxref.nom_vern AS vernac_name, + bdc_statut.statut_type AS statut_type, + bdc_statut.statut AS statut, + bdc_statut.article AS article, + bdc_statut.doc_url AS doc_url, + synthese_zh.date_max AS last_date, + synthese_zh.observers AS observer, + synthese_zh.organisme AS organisme, + (select count(cd_nom) from synthese_taxa where id_zh = synthese_zh.id_zh and cd_nom = taxref.cd_nom)::integer AS obs_nb + FROM synthese_zh + LEFT JOIN taxonomie.taxref taxref ON synthese_zh.cd_nom = taxref.cd_nom + LEFT JOIN bdc_statut ON bdc_statut.cd_nom = taxref.cd_nom + WHERE synthese_zh.id_zh IS NOT NULL + AND (synthese_zh.date_max::timestamp > (NOW()::timestamp - interval '20 years')) + AND taxref.phylum != 'Chordata' + AND taxref.regne = 'Animalia' + AND ( + bdc_statut.cd_sig = 'ETATFRA' + OR bdc_statut.cd_sig IN + ( + SELECT + DISTINCT('INSEER' || lim.insee_reg) AS cd_sig + FROM pr_zh.t_zh tzh + LEFT JOIN pr_zh.cor_zh_area cza ON cza.id_zh = tzh.id_zh + LEFT JOIN ref_geo.l_areas lareas ON cza.id_area = lareas.id_area + LEFT JOIN ref_geo.li_municipalities lim ON lim.id_area = lareas.id_area + WHERE tzh.id_zh = synthese_zh.id_zh + AND lim.insee_reg IS NOT NULL + ) + OR bdc_statut.cd_sig IN + ( + SELECT + DISTINCT('INSEED' || lareas.area_code) AS cd_sig + FROM pr_zh.t_zh tzh + LEFT JOIN pr_zh.cor_zh_area cza ON cza.id_zh = tzh.id_zh + LEFT JOIN ref_geo.l_areas lareas ON cza.id_area = lareas.id_area + WHERE tzh.id_zh = synthese_zh.id_zh + AND id_type = (SELECT id_type FROM ref_geo.bib_areas_types WHERE type_code = 'DEP') + AND lareas.area_code IS NOT NULL + ) + OR (bdc_statut.statut_type in ('Liste rouge', 'Réglementation', 'Protection', 'Directives européennes') and bdc_statut.cd_sig = 'TERFXFR') + ) + GROUP BY taxref.nom_complet, taxref.nom_vern, taxref.classe, synthese_zh.id_zh, taxref.cd_nom, bdc_statut.statut_type, bdc_statut.article, bdc_statut.statut, bdc_statut.doc_url, synthese_zh.date_max, synthese_zh.observers, synthese_zh.organisme; + + CREATE OR REPLACE VIEW pr_zh.flora AS + WITH + synthese_taxa AS ( + SELECT + synthese.id_synthese, + ( + SELECT t_zh.id_zh + FROM pr_zh.t_zh + WHERE st_intersects(st_setsrid(t_zh.geom, 4326), st_setsrid(synthese.the_geom_point, 4326)) + ) AS id_zh, + synthese.cd_nom, + synthese.date_max, + synthese.observers, + ( + SELECT organisme + FROM utilisateurs.v_userslist_forall_applications + WHERE nom_role || ' ' || prenom_role = synthese.observers limit 1 + ) + FROM gn_synthese.synthese + ), + synthese_zh AS ( + SELECT DISTINCT ON (id_zh, cd_nom) * + FROM synthese_taxa + WHERE id_zh IS NOT null + ORDER BY id_zh, cd_nom, date_max DESC + ), + bdc_statut AS ( + SELECT + cd_nom, + cd_sig, + regroupement_type AS statut_type, + lb_type_statut || ' - ' || label_statut AS statut, + full_citation AS article, + doc_url AS doc_url + FROM taxonomie.bdc_statut + WHERE ( + regroupement_type = 'Liste rouge' + AND code_statut IN ('VU', 'EN', 'CR') + ) + OR ( + regroupement_type IN ('ZNIEFF', 'Réglementation', 'Protection', 'Directives européennes') + ) + ) + + SELECT + synthese_zh.id_zh, + taxref.cd_nom, + taxref.classe AS group_class, + taxref.ordre AS group_order, + taxref.nom_complet AS scientific_name, + taxref.nom_vern AS vernac_name, + bdc_statut.statut_type AS statut_type, + bdc_statut.statut AS statut, + bdc_statut.article AS article, + bdc_statut.doc_url AS doc_url, + synthese_zh.date_max AS last_date, + synthese_zh.observers AS observer, + synthese_zh.organisme AS organisme, + (select count(cd_nom) from synthese_taxa where id_zh = synthese_zh.id_zh and cd_nom = taxref.cd_nom)::integer AS obs_nb + FROM synthese_zh + LEFT JOIN taxonomie.taxref taxref ON synthese_zh.cd_nom = taxref.cd_nom + LEFT JOIN bdc_statut ON bdc_statut.cd_nom = taxref.cd_nom + WHERE synthese_zh.id_zh IS NOT NULL + AND (synthese_zh.date_max::timestamp > (NOW()::timestamp - interval '20 years')) + AND taxref.regne = 'Plantae' + AND ( + bdc_statut.cd_sig = 'ETATFRA' + OR bdc_statut.cd_sig IN + ( + SELECT + DISTINCT('INSEER' || lim.insee_reg) AS cd_sig + FROM pr_zh.t_zh tzh + LEFT JOIN pr_zh.cor_zh_area cza ON cza.id_zh = tzh.id_zh + LEFT JOIN ref_geo.l_areas lareas ON cza.id_area = lareas.id_area + LEFT JOIN ref_geo.li_municipalities lim ON lim.id_area = lareas.id_area + WHERE tzh.id_zh = synthese_zh.id_zh + AND lim.insee_reg IS NOT NULL + ) + OR bdc_statut.cd_sig IN + ( + SELECT + DISTINCT('INSEED' || lareas.area_code) AS cd_sig + FROM pr_zh.t_zh tzh + LEFT JOIN pr_zh.cor_zh_area cza ON cza.id_zh = tzh.id_zh + LEFT JOIN ref_geo.l_areas lareas ON cza.id_area = lareas.id_area + WHERE tzh.id_zh = synthese_zh.id_zh + AND id_type = (SELECT id_type FROM ref_geo.bib_areas_types WHERE type_code = 'DEP') + AND lareas.area_code IS NOT NULL + ) + OR (bdc_statut.statut_type in ('Liste rouge', 'Réglementation', 'Protection', 'Directives européennes') and bdc_statut.cd_sig = 'TERFXFR') + ) + GROUP BY taxref.nom_complet, taxref.nom_vern, taxref.classe, synthese_zh.id_zh, taxref.cd_nom, bdc_statut.statut_type, bdc_statut.article, bdc_statut.statut, bdc_statut.doc_url, synthese_zh.date_max, synthese_zh.observers, synthese_zh.organisme; + """ + ) diff --git a/backend/gn_module_zh/migrations/data/script_create_taxon_view.sh b/backend/gn_module_zh/migrations/data/script_create_taxon_view.sh index d1d98c7c..691feffd 100755 --- a/backend/gn_module_zh/migrations/data/script_create_taxon_view.sh +++ b/backend/gn_module_zh/migrations/data/script_create_taxon_view.sh @@ -33,7 +33,7 @@ for val in ${ViewArray[@]}; do branch="taxref.phylum != 'Chordata' AND taxref.regne = 'Animalia'" fi query=(" - CREATE OR REPLACE VIEW pr_zh.$val AS + CREATE MATERIALIZED VIEW pr_zh.vm_$val AS WITH synthese_taxa AS ( SELECT diff --git a/backend/gn_module_zh/model/cards.py b/backend/gn_module_zh/model/cards.py index 795b5e19..e1651c5c 100644 --- a/backend/gn_module_zh/model/cards.py +++ b/backend/gn_module_zh/model/cards.py @@ -672,7 +672,7 @@ def other_ref_geo(self, ref_geo): refs = [] for ref_infos in CorZhArea.get_ref_geo_info(self.id_zh, id_types): for info in ref_infos: - type_code = DB.session.get(BibAreasTypes, info.LAreas.id_type) + type_code = DB.session.get(BibAreasTypes, info.LAreas.id_type).type_code refs.append( { "area_name": info.LAreas.area_name, @@ -809,7 +809,7 @@ def __init__(self, id_area, id_doc_type, id_cors, remark): def __str__(self): return { - "commune": DB.session.get(LAreas, self.id_area), + "commune": DB.session.get(LAreas, self.id_area).id_area, "type_doc": Utils.get_mnemo(self.id_doc_type), "type_classement": [ Utils.get_mnemo( diff --git a/backend/gn_module_zh/tasks.py b/backend/gn_module_zh/tasks.py new file mode 100644 index 00000000..fd257855 --- /dev/null +++ b/backend/gn_module_zh/tasks.py @@ -0,0 +1,41 @@ +import os + +from datetime import datetime, timedelta +from pathlib import Path + +from sqlalchemy import func +from celery.utils.log import get_task_logger +from celery.schedules import crontab + +from flask import current_app +from geonature.utils.celery import celery_app + +from geonature.utils.env import db +from geonature.utils.config import config + +logger = get_task_logger(__name__) + + +@celery_app.on_after_finalize.connect +def setup_periodic_tasks(sender, **kwargs): + ct = config["ZONES_HUMIDES"]["TAXON_VM_CRONTAB"] + minute, hour, day_of_month, month_of_year, day_of_week = ct.split(" ") + sender.add_periodic_task( + crontab( + minute=minute, + hour=hour, + day_of_week=day_of_week, + day_of_month=day_of_month, + month_of_year=month_of_year, + ), + refresh_taxon_vm.s(), + name="Refresh taxon vms", + ) + + +@celery_app.task(bind=True) +def refresh_taxon_vm(self): + logger.info("Refresh taxon vms...") + db.session.execute(func.pr_zh.refresh_taxon_materialized_views()) + db.session.commit() + logger.info("Taxon vms refreshed.") diff --git a/doc/admin.md b/doc/admin.md index bd4a66bb..4081a7a0 100644 --- a/doc/admin.md +++ b/doc/admin.md @@ -26,13 +26,19 @@ Si l'administrateur désire qu'un inventaire n'apparaisse plus dans la section 6 ## **5 - Téléchargement des listes de taxons** +### Fonctionnement + Lorsque l'utilisateur clique sur "générer la liste des espèces" dans l'onglet 5, l'application génère 3 fichiers csv correspondant aux taxons de flore, faune vertébrée et invertébrée protégés et observés au sein du périmètre de la zone humide. Voir la documentation utilisateur du module pour plus de détails sur les critères retenus pour la composition de cette liste. A noter qu’il s’agit d’une liste de taxons et non pas d’une liste d’occurrences de taxons (les observations liées à 1 taxon représentent donc 1 seule ligne). Chaque clic sur le bouton génère les fichiers, ces derniers étant stockés sur le serveur (et donc constamment disponibles au téléchargement) dans le dossier `static`. -Par défaut, les 3 vues (`vertebrates_view_name`, `invertebrates_view_name` et `flore_view_name`) sont paramétrées pour : +Par défaut, les 3 vues matérialisées (`vertebrates_view_name`, `invertebrates_view_name` et `flore_view_name`) sont paramétrées pour : -- lister les taxons présents dans la synthèse GeoNature de l'instance sur laquelle est déployé le module ZH. Les vues utilisent donc la table `gn_synthese.synthese` en base de données. +- lister les taxons présents dans la synthèse GeoNature de l'instance sur laquelle est déployé le module ZH. Les vues matérialisées utilisent donc la table `gn_synthese.synthese` en base de données. - utiliser les statuts d’évaluation, protection et menace listés dans la table `taxonomie.bdc_statut` +![columns](taxons.png) + +### Changer la source des données + Si l'administrateur veut changer la source de données, par exemple se brancher sur la synthèse d'une autre instance en configurant un foreign data wrapper, il devra supprimer les vues déjà existantes en base de données puis les recréer en respectant leur structure : - `id_zh` - integer : id de la zh concernée @@ -52,9 +58,17 @@ Si l'administrateur veut changer la source de données, par exemple se brancher L’association `id_zh`/`cd_nom` doit être unique puisque la vue liste les taxons protégés présents dans chaque zone humide. -Le script `data/script_create_taxon_view.sh` permet d’aider la génération des vues en indiquant la table source des occurrences de taxons et la table listant les statuts d’évaluation, protection et menaces. Etant donné que par défaut les vues sont construites sur la base de la structure des tables `gn_synthese.synthese` et `taxonomie.bdc_statut` de GeoNature, ce script fonctionne de manière optimale en utilisant des sources de données dont la structure est identique, c’est-à-dire provenant de GeoNature, que ce soit en local (= l’instance sur laquelle est installé le module ZH) ou à l’extérieur (ex : un foreign data wrapper vers les données d’un autre GeoNature). Si l’administrateur désire utiliser d’autres sources de données structurées différemment, il devra modifier le code sql de ce script pour obtenir la structure attendue (décrite ci-dessus) des vues. +Le script `data/script_create_taxon_view.sh` permet d’aider la génération des vues matérialisées en indiquant la table source des occurrences de taxons et la table listant les statuts d’évaluation, protection et menaces. Etant donné que par défaut les vues matérialisées sont construites sur la base de la structure des tables `gn_synthese.synthese` et `taxonomie.bdc_statut` de GeoNature, ce script fonctionne de manière optimale en utilisant des sources de données dont la structure est identique, c’est-à-dire provenant de GeoNature, que ce soit en local (= l’instance sur laquelle est installé le module ZH) ou à l’extérieur (ex : un foreign data wrapper vers les données d’un autre GeoNature). Si l’administrateur désire utiliser d’autres sources de données structurées différemment, il devra modifier le code sql de ce script pour obtenir la structure attendue (décrite ci-dessus) des vues. -![columns](taxons.png) +### Rafraichissement des vues matérialisées + +Les vues matérisalisées sont mises à jour automatiquement à fréquence définie, par défaut toutes les 12 heures. Si toutefois, vous souhaitez diminuer ou augmenter la durée entre chaque mise à jour, définissez cette dernière dans le fichier de configuration (``zones_humides_config.toml``) dans la variable ``TAXON_VM_CRONTAB``. + + TAXON_VM_CRONTAB ="0 0,12 * * *" + +Ce paramètre est composé de cinq valeurs, chacune séparée par un espace: minute, heure, jour du mois, mois de l'année, journée de la semaine. Dans l'exemple ci-dessus, il est indiqué que la mise à jour sera effectuée toutes les 12 heures. Pour plus d'informations, vous pouvez consulter la documentation de Celery à ce sujet : https://docs.celeryq.dev/en/stable/userguide/periodic-tasks.html#crontab-schedules. + +**Note** : Si vous ne voulez pas définir un des paramètres de périodicité, utilisez un astérisque (``*``). ## **6- Les ressources documentaires** diff --git a/frontend/app/services/hierarchy.service.ts b/frontend/app/services/hierarchy.service.ts index 8f2359a6..16aefa0d 100644 --- a/frontend/app/services/hierarchy.service.ts +++ b/frontend/app/services/hierarchy.service.ts @@ -52,6 +52,14 @@ export class HierarchyService { this._toastr.warning("La ZH n'est présente dans aucun bassin versant", '', { closeButton: true, }); + } else if (error.status === 400) { + this._toastr.warning( + this._error['errors'].filter((i) => error.error['message'] === i.api)[0].front, + '', + { + closeButton: true, + } + ); } }, () => { @@ -66,7 +74,7 @@ export class HierarchyService { this.items = []; return; } - + this.items = [{ name: '', active: true, qualification: '', knowledge: '', note: '' }]; // cat 1 diff --git a/setup.py b/setup.py index 8a25e30e..9ebd181c 100644 --- a/setup.py +++ b/setup.py @@ -32,6 +32,7 @@ "config_schema = gn_module_zh.conf_schema_toml:GnModuleSchemaConf", "alembic_branch = gn_module_zh:ALEMBIC_BRANCH", "migrations = gn_module_zh:migrations", + "tasks = gn_module_zh.tasks", ], }, classifiers=[