Skip to content

Commit

Permalink
Récursivité dans la récupération des critères de sensibilité - cf #284
Browse files Browse the repository at this point in the history
  • Loading branch information
amandine-sahl committed Jul 2, 2020
1 parent 5f0eaef commit 9fd49be
Show file tree
Hide file tree
Showing 2 changed files with 150 additions and 18 deletions.
45 changes: 27 additions & 18 deletions data/core/sensitivity.sql
Original file line number Diff line number Diff line change
Expand Up @@ -125,13 +125,11 @@ WITH DATA;

--- Fonction calcul de la sensibilité

CREATE OR REPLACE FUNCTION gn_sensitivity.get_id_nomenclature_sensitivity(
my_date_obs date,
my_cd_ref integer,
my_geom geometry,
my_criterias jsonb)
RETURNS integer AS
$BODY$
CREATE OR REPLACE FUNCTION gn_sensitivity.get_id_nomenclature_sensitivity(my_date_obs date, my_cd_ref integer, my_geom geometry, my_criterias jsonb)
RETURNS integer
LANGUAGE plpgsql
IMMUTABLE
AS $function$
DECLARE
niv_precis integer;
niv_precis_null integer;
Expand Down Expand Up @@ -184,13 +182,26 @@ BEGIN
) THEN
-- Si le critère est remplis
niv_precis := (
SELECT DISTINCT id_nomenclature_sensitivity
FROM gn_sensitivity.t_sensitivity_rules_cd_ref s
JOIN gn_sensitivity.cor_sensitivity_criteria c USING(id_sensitivity)
JOIN (SELECT * FROM jsonb_each_text(my_criterias)) a
ON c.id_criteria = a.value::int
WHERE s.cd_ref = my_cd_ref
LIMIT 1

WITH RECURSIVE h_val(KEY, value, id_broader) AS (
SELECT KEY, value::int, id_broader
FROM (SELECT * FROM jsonb_each_text(my_criterias)) d
JOIN ref_nomenclatures.t_nomenclatures tn
ON tn.id_nomenclature = d.value::int
UNION
SELECT KEY, id_nomenclature , tn.id_broader
FROM ref_nomenclatures.t_nomenclatures tn
JOIN h_val
ON tn.id_nomenclature = h_val.id_broader
WHERE NOT id_nomenclature = 0
)
SELECT DISTINCT id_nomenclature_sensitivity
FROM gn_sensitivity.t_sensitivity_rules_cd_ref s
JOIN gn_sensitivity.cor_sensitivity_criteria c USING(id_sensitivity)
JOIN h_val a
ON c.id_criteria = a.value
WHERE s.cd_ref = my_cd_ref
LIMIT 1
);
IF niv_precis IS NULL THEN
niv_precis := (SELECT ref_nomenclatures.get_id_nomenclature('SENSIBILITE'::text, '0'::text));
Expand Down Expand Up @@ -234,10 +245,8 @@ BEGIN
return niv_precis;

END;
$BODY$
LANGUAGE plpgsql IMMUTABLE
COST 100;

$function$
;


-- Table permettant de stocker la sensibilité d'une donnée issue de la synthèse
Expand Down
123 changes: 123 additions & 0 deletions data/migrations/2.4.0to2.4.2.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,123 @@

CREATE OR REPLACE FUNCTION gn_sensitivity.get_id_nomenclature_sensitivity(my_date_obs date, my_cd_ref integer, my_geom geometry, my_criterias jsonb)
RETURNS integer
LANGUAGE plpgsql
IMMUTABLE
AS $function$
DECLARE
niv_precis integer;
niv_precis_null integer;
BEGIN

niv_precis_null := (SELECT ref_nomenclatures.get_id_nomenclature('SENSIBILITE'::text, '0'::text));

-- ##########################################
-- TESTS unicritère
-- => Permet de voir si un critère est remplis ou non de façon à limiter au maximum
-- la requete globale qui croise l'ensemble des critères
-- ##########################################

-- Paramètres cd_ref
IF NOT EXISTS (
SELECT 1
FROM gn_sensitivity.t_sensitivity_rules_cd_ref s
WHERE s.cd_ref = my_cd_ref
) THEN
return niv_precis_null;
END IF;

-- Paramètres durée de validité de la règle
IF NOT EXISTS (
SELECT 1
FROM gn_sensitivity.t_sensitivity_rules_cd_ref s
WHERE s.cd_ref = my_cd_ref
AND (date_part('year', CURRENT_TIMESTAMP) - sensitivity_duration) <= date_part('year', my_date_obs)
) THEN
return niv_precis_null;
END IF;

-- Paramètres période d'observation
IF NOT EXISTS (
SELECT 1
FROM gn_sensitivity.t_sensitivity_rules_cd_ref s
WHERE s.cd_ref = my_cd_ref
AND (to_char(my_date_obs, 'MMDD') between to_char(s.date_min, 'MMDD') and to_char(s.date_max, 'MMDD') )
) THEN
return niv_precis_null;
END IF;

-- Paramètres critères biologiques
-- S'il existe un critère pour ce taxon
IF EXISTS (
SELECT 1
FROM gn_sensitivity.t_sensitivity_rules_cd_ref s
JOIN gn_sensitivity.cor_sensitivity_criteria c USING(id_sensitivity)
WHERE s.cd_ref = my_cd_ref
) THEN
-- Si le critère est remplis
niv_precis := (

WITH RECURSIVE h_val(KEY, value, id_broader) AS (
SELECT KEY, value::int, id_broader
FROM (SELECT * FROM jsonb_each_text(my_criterias)) d
JOIN ref_nomenclatures.t_nomenclatures tn
ON tn.id_nomenclature = d.value::int
UNION
SELECT KEY, id_nomenclature , tn.id_broader
FROM ref_nomenclatures.t_nomenclatures tn
JOIN h_val
ON tn.id_nomenclature = h_val.id_broader
WHERE NOT id_nomenclature = 0
)
SELECT DISTINCT id_nomenclature_sensitivity
FROM gn_sensitivity.t_sensitivity_rules_cd_ref s
JOIN gn_sensitivity.cor_sensitivity_criteria c USING(id_sensitivity)
JOIN h_val a
ON c.id_criteria = a.value
WHERE s.cd_ref = my_cd_ref
LIMIT 1
);
IF niv_precis IS NULL THEN
niv_precis := (SELECT ref_nomenclatures.get_id_nomenclature('SENSIBILITE'::text, '0'::text));
return niv_precis;
END IF;
END IF;



-- ##########################################
-- TESTS multicritères
-- => Permet de voir si l'ensemble des critères sont remplis
-- ##########################################

-- Paramètres durée, zone géographique, période de l'observation et critères biologique
SELECT INTO niv_precis s.id_nomenclature_sensitivity
FROM (
SELECT s.*, l.geom, c.id_criteria, c.id_type_nomenclature
FROM gn_sensitivity.t_sensitivity_rules_cd_ref s
LEFT OUTER JOIN gn_sensitivity.cor_sensitivity_area USING(id_sensitivity)
LEFT OUTER JOIN gn_sensitivity.cor_sensitivity_criteria c USING(id_sensitivity)
LEFT OUTER JOIN ref_geo.l_areas l USING(id_area)
) s
WHERE my_cd_ref = s.cd_ref
AND (st_intersects(my_geom, s.geom) OR s.geom IS NULL) -- paramètre géographique
AND (-- paramètre période
(to_char(my_date_obs, 'MMDD') between to_char(s.date_min, 'MMDD') and to_char(s.date_max, 'MMDD') )
)
AND ( -- paramètre duré de validité de la règle
(date_part('year', CURRENT_TIMESTAMP) - sensitivity_duration) <= date_part('year', my_date_obs)
)
AND ( -- paramètre critères
s.id_criteria IN (SELECT value::int FROM jsonb_each_text(my_criterias)) OR s.id_criteria IS NULL
);

IF niv_precis IS NULL THEN
niv_precis := niv_precis_null;
END IF;


return niv_precis;

END;
$function$
;

0 comments on commit 9fd49be

Please sign in to comment.