Skip to content

Commit

Permalink
Merge pull request #9 from lpoaura/develop
Browse files Browse the repository at this point in the history
Some new features
  • Loading branch information
lpofredc committed Nov 24, 2021
2 parents 6d21c1c + dedad14 commit 97d9b87
Show file tree
Hide file tree
Showing 5 changed files with 190 additions and 6 deletions.
64 changes: 64 additions & 0 deletions 00_init_db.sql
Original file line number Diff line number Diff line change
Expand Up @@ -153,6 +153,70 @@ CREATE INDEX i_t_c_synthese_extended_bird_breed_code ON src_lpodatas.t_c_synthes
CREATE INDEX i_t_c_synthese_extended_project_code ON src_lpodatas.t_c_synthese_extended (project_code)
;

CREATE VIEW src_lpodatas.v_c_observations
( id_synthese, uuid, source, source_id_data, source_id_sp, taxref_cdnom, groupe_taxo, group1_inpn
, group2_inpn, taxon_vrai, nom_vern, nom_sci, observateur, pseudo_observer_uid, oiso_code_nidif
, oiso_statut_nidif, cs_colo_repro, cs_is_gite, cs_periode, nombre_total, code_estimation, date, date_an
, altitude, mortalite, mortalite_cause, geom, exp_excl, code_etude, commentaires, pers_morale, comportement
, precision, details, place, id_formulaire, derniere_maj, is_valid, donnee_cachee, is_present)
AS
SELECT
s.id_synthese
, s.unique_id_sinp AS uuid
, ts.name_source AS source
, s.entity_source_pk_value AS source_id_data
, se.id_sp_source AS source_id_sp
, s.cd_nom AS taxref_cdnom
, se.taxo_group AS groupe_taxo
, t.group1_inpn
, t.group2_inpn
, se.taxo_real AS taxon_vrai
, se.common_name AS nom_vern
, t.lb_nom AS nom_sci
, s.observers AS observateur
, se.pseudo_observer_uid
, se.bird_breed_code AS oiso_code_nidif
, se.bird_breed_status AS oiso_statut_nidif
, se.bat_breed_colo AS cs_colo_repro
, se.bat_is_gite AS cs_is_gite
, se.bat_period AS cs_periode
, s.count_max AS nombre_total
, se.estimation_code AS code_estimation
, s.date_max AS date
, se.date_year AS date_an
, s.altitude_max AS altitude
, se.mortality AS mortalite
, se.mortality_cause AS mortalite_cause
, s.the_geom_local AS geom
, se.export_excluded AS exp_excl
, se.project_code AS code_etude
, s.comment_description AS commentaires
, se.juridical_person AS pers_morale
, se.behaviour AS comportement
, se.geo_accuracy AS precision
, se.details
, se.place
, se.id_form AS id_formulaire
, s.meta_update_date AS derniere_maj
, (s.id_nomenclature_valid_status IN (SELECT
t_nomenclatures.id_nomenclature
FROM
ref_nomenclatures.t_nomenclatures
WHERE
t_nomenclatures.id_type =
ref_nomenclatures.get_id_nomenclature_type('STATUT_VALID'::CHARACTER VARYING)
AND (t_nomenclatures.cd_nomenclature::TEXT = ANY
(ARRAY ['1'::CHARACTER VARYING::TEXT, '2'::CHARACTER VARYING::TEXT])))) AS is_valid
, se.is_hidden AS donnee_cachee
, s.id_nomenclature_observation_status = ref_nomenclatures.get_id_nomenclature('STATUT_OBS'::CHARACTER VARYING,
'Pr'::CHARACTER VARYING) AS is_present
FROM
gn_synthese.synthese s
LEFT JOIN src_lpodatas.t_c_synthese_extended se ON s.id_synthese = se.id_synthese
JOIN gn_synthese.t_sources ts ON s.id_source = ts.id_source
JOIN taxonomie.taxref t ON s.cd_nom = t.cd_nom
;


CREATE TABLE src_lpodatas.t_c_rules_diffusion_level
(
Expand Down
2 changes: 1 addition & 1 deletion 03_taxonomie.sql
Original file line number Diff line number Diff line change
Expand Up @@ -13,7 +13,7 @@ CREATE TABLE taxonomie.cor_c_vn_taxref
)
;

CREATE UNIQUE INDEX ON taxonomie.cor_c_vn_taxref (vn_id, taxref_id)
CREATE UNIQUE INDEX i_uniq_cor_c_vn_taxref ON taxonomie.cor_c_vn_taxref (vn_id, taxref_id)
;

COMMENT ON TABLE taxonomie.cor_c_vn_taxref IS 'Correlation between taxref cd_nom (taxref) and VisioNature species id (src_vn.species).'
Expand Down
38 changes: 38 additions & 0 deletions 07_functions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -6,6 +6,7 @@ A collection of various helper fonctions


/* Function to get taxo group from visionature id_species */

BEGIN
;

Expand Down Expand Up @@ -252,5 +253,42 @@ END;
$$ LANGUAGE plpgsql
;

DROP FUNCTION IF EXISTS src_lpodatas.fct_c_get_committees_validation_status(_committees_validation JSONB)
;

CREATE OR REPLACE FUNCTION src_lpodatas.fct_c_get_committees_validation_status(_committees_validation JSONB)
RETURNS TEXT[] AS
$$
DECLARE
the_values TEXT[];
the_rec RECORD;
BEGIN
FOR the_rec IN (SELECT jsonb_object_keys(_committees_validation) AS key)
LOOP
SELECT
array_append(the_values, _committees_validation ->> the_rec.key)
INTO the_values;
END LOOP;
RETURN the_values;
END;
$$ LANGUAGE plpgsql
;

DROP FUNCTION IF EXISTS src_lpodatas.fct_c_get_committees_validation_is_accepted(_committees_validation JSONB)
;

CREATE OR REPLACE FUNCTION src_lpodatas.fct_c_get_committees_validation_is_accepted(_committees_validation JSONB)
RETURNS BOOLEAN AS
$$
DECLARE
is_accepted BOOLEAN;
BEGIN
SELECT 'ACCEPTED' = ANY (src_lpodatas.fct_c_get_committees_validation_status(_committees_validation)) INTO is_accepted;
RETURN is_accepted;
END;
$$ LANGUAGE plpgsql
;


COMMIT
;
12 changes: 7 additions & 5 deletions 08_upsert_observations.sql
Original file line number Diff line number Diff line change
Expand Up @@ -65,7 +65,7 @@ DECLARE
the_altitude_max INTEGER;
_the_geom_4326 GEOMETRY(Geometry, 4326);
_the_geom_point GEOMETRY(Point, 4326);
_the_geom_local GEOMETRY(Geometry, 4326);
_the_geom_local GEOMETRY(Geometry, :local_srid);
the_date_min TIMESTAMP;
the_date_max TIMESTAMP;
the_validation_comment TEXT;
Expand Down Expand Up @@ -206,10 +206,12 @@ BEGIN
SELECT
-- When chr or chn accepted then certain, when admin_hidden then is douteux else probable.
CASE
WHEN new.item #>> '{observers,0,committees_validation,chr}' LIKE 'ACCEPTED'
OR new.item #>> '{observers,0,committees_validation,chn}' LIKE 'ACCEPTED' THEN
WHEN src_lpodatas.fct_c_get_committees_validation_is_accepted(new.item #> '{observers,0,committees_validation}')
THEN
ref_nomenclatures.get_id_nomenclature('STATUT_VALID', '1')
WHEN cast(new.item #>> '{observers,0,admin_hidden}' AS BOOLEAN) THEN
WHEN cast(new.item #>> '{observers,0,admin_hidden}' AS BOOLEAN) OR
NOT src_lpodatas.fct_c_get_committees_validation_is_accepted(new.item #> '{observers,0,committees_validation}')
THEN
ref_nomenclatures.get_id_nomenclature('STATUT_VALID', '3')
ELSE
ref_nomenclatures.get_id_nomenclature('STATUT_VALID', '2')
Expand Down Expand Up @@ -314,7 +316,7 @@ ref_nomenclatures.get_id_nomenclature('TYP_DENBR', 'ind')
_the_geom_4326
INTO _the_geom_point;
SELECT
public.st_transform(_the_geom_4326, (gn_commons.get_default_parameter('local_srid'))::int)
public.st_transform(_the_geom_4326, (gn_commons.get_default_parameter('local_srid'))::INT)
INTO _the_geom_local;
SELECT
to_timestamp(cast(new.item #>> '{date,@timestamp}' AS DOUBLE PRECISION))
Expand Down
80 changes: 80 additions & 0 deletions addons/exclude_data_out_of_coverd_area.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,80 @@
/*
Filtrage territorialisé des données issues de l'API VN depuis l'appli Client-API-VN
Objectif: Supprimer les données de src_vn_json.observations_json qui ne sont pas comprises dans VN_COVER :
PREREQUIS
=========
Le filtrage des données se fait sur un zonage intégré à la table ref_geo.l_areas dont le type_code est VN_COVER.
Il faut dont créer un type de code VN_COVER dans ref_geo.bib_areas_type et créer un zonage associé à ce type dans reg_geo.l_areas.
Suppression des données hors zone si présentes en bdd
*/

/*
Si des données hors-zone sont déjà présentes dans la bdd. Il est possible de les supprimer avec la requête suivante.
*/
BEGIN;

DELETE FROM src_vn_json.observations_json
WHERE st_disjoint(
public.st_setsrid (public.st_makepoint((item #>> '{observers,0,coord_lon}')::float, (item #>> '{observers,0,coord_lat}')::float), 4326),
st_transform((SELECT geom FROM ref_geo.l_areas WHERE id_type=ref_geo.get_id_area_type('VN_COVER')), 4326)
);

COMMIT;

/* MISE EN PLACE DU TRIGGER D'EXCLUSION */
BEGIN;

CREATE OR REPLACE FUNCTION src_vn_json.fct_tri_c_check_vn_cover()
RETURNS TRIGGER
LANGUAGE plpgsql
AS
$function$
DECLARE
the_geom_4326 GEOMETRY(Geometry, 4326);
the_vn_cover GEOMETRY(Geometry, 4326);

BEGIN
SELECT
public.st_setsrid(public.st_makepoint((new.item #>> '{observers,0,coord_lon}')::FLOAT,
(new.item #>> '{observers,0,coord_lat}')::FLOAT), 4326)
INTO the_geom_4326;
SELECT
st_transform(geom, 4326)
INTO the_vn_cover
FROM
ref_geo.l_areas
WHERE
id_type = ref_geo.get_id_area_type('VN_COVER')
LIMIT 1;

IF (st_intersects(the_geom_4326, the_vn_cover)) THEN
RAISE DEBUG 'In COVER';
RETURN new;
ELSE
RAISE DEBUG 'Out COVER';
RETURN NULL;
END IF;

END;
$function$
;


DROP TRIGGER IF EXISTS tri_c_check_vn_cover ON src_vn_json.observations_json
;

CREATE TRIGGER tri_c_check_vn_cover
BEFORE INSERT OR UPDATE
ON src_vn_json.observations_json
FOR EACH ROW
EXECUTE FUNCTION src_vn_json.fct_tri_c_check_vn_cover()
;

COMMIT
;

0 comments on commit 97d9b87

Please sign in to comment.