Skip to content

Commit

Permalink
Merge pull request #7 from lpoaura/develop
Browse files Browse the repository at this point in the history
v1.2.0
  • Loading branch information
lpofredc authored Oct 13, 2021
2 parents 9053eb7 + ca635fd commit 6d21c1c
Show file tree
Hide file tree
Showing 25 changed files with 3,449 additions and 44,727 deletions.
215 changes: 171 additions & 44 deletions 00_init_db.sql
Original file line number Diff line number Diff line change
@@ -1,20 +1,29 @@
/*
Child table with specific datas from:
- VisioNature
- dbChiroWeb
INIT DB
-------
Generate extended data table to store specific datas not in GeoNature Synthese table.
Adapted to store data from VisioNature and dbChiroWeb
*/
CREATE SCHEMA IF NOT EXISTS AUTHORIZATION gnadm;

DROP TABLE IF EXISTS .t_c_synthese_extended;

CREATE TABLE IF NOT EXISTS .t_c_synthese_extended
BEGIN
;

CREATE SCHEMA IF NOT EXISTS src_lpodatas
;

DROP TABLE IF EXISTS src_lpodatas.t_c_synthese_extended
;

CREATE TABLE IF NOT EXISTS src_lpodatas.t_c_synthese_extended
(
id_synthese INTEGER PRIMARY KEY REFERENCES gn_synthese.synthese (id_synthese),
id_sp_source INTEGER,
taxo_group VARCHAR(50),
taxo_real BOOLEAN,
common_name VARCHAR(250),
pseudo_observer_uid VARCHAR(200),
observers VARCHAR(200),
bird_breed_code INTEGER,
bird_breed_status VARCHAR(20),
bat_breed_colo BOOLEAN,
Expand All @@ -36,42 +45,160 @@ CREATE TABLE IF NOT EXISTS .t_c_synthese_extended
is_valid BOOLEAN,
private_comment TEXT,
is_hidden BOOLEAN DEFAULT FALSE
);

COMMENT ON COLUMN .t_c_synthese_extended.id_sp_source IS 'Code espèce de la source (VisioNature/dbChiroWeb)';
COMMENT ON COLUMN .t_c_synthese_extended.taxo_group IS 'Groupe taxonomique VisioNature';
COMMENT ON COLUMN .t_c_synthese_extended.taxo_real IS 'True si Taxon Vrai';
COMMENT ON COLUMN .t_c_synthese_extended.common_name IS 'Nom vernaculaire';
COMMENT ON COLUMN .t_c_synthese_extended.pseudo_observer_uid IS 'Identifiant chiffré de l''Observateur pour anonymisation';
COMMENT ON COLUMN .t_c_synthese_extended.bird_breed_code IS 'Codes "Biolovision" de nidification https://wiki.biolovision.net/Correspondance_codes_atlas';
COMMENT ON COLUMN .t_c_synthese_extended.bird_breed_status IS 'Statut de nidification simplifié (Nicheur possible, probable, certain) d''après oiso_code_nidif';
COMMENT ON COLUMN .t_c_synthese_extended.bat_breed_colo IS 'Colonie de reproduction de chauves-souris';
COMMENT ON COLUMN .t_c_synthese_extended.bat_is_gite IS 'Gite à chauves-souris';
COMMENT ON COLUMN .t_c_synthese_extended.bat_period IS 'Période du cycle annuel des chauves-souris (hivernage, transit printanier ou automnal, estivage)';
COMMENT ON COLUMN .t_c_synthese_extended.estimation_code IS 'Code caractérisant le type d''estimation du comptage';
COMMENT ON COLUMN .t_c_synthese_extended.date_year IS 'Année de l''observation';
COMMENT ON COLUMN .t_c_synthese_extended.mortality IS 'Est une donnée de mortalité';
COMMENT ON COLUMN .t_c_synthese_extended.mortality_cause IS 'Cause identifiée de la mortalité';
COMMENT ON COLUMN .t_c_synthese_extended.export_excluded IS 'A exclure des exports';
COMMENT ON COLUMN .t_c_synthese_extended.project_code IS 'Code étude';
COMMENT ON COLUMN .t_c_synthese_extended.juridical_person IS 'Personne morale';
COMMENT ON COLUMN .t_c_synthese_extended.behaviour IS 'Liste (format ARRAY) des comportements observés';
COMMENT ON COLUMN .t_c_synthese_extended.geo_accuracy IS 'Précision géographique de la donnée';
COMMENT ON COLUMN .t_c_synthese_extended.details IS 'Détails de la donnée (format JSON)';
COMMENT ON COLUMN .t_c_synthese_extended.id_place IS 'Identifiant du lieu-dit';
COMMENT ON COLUMN .t_c_synthese_extended.place IS 'Nom du Lieu-dit';
COMMENT ON COLUMN .t_c_synthese_extended.id_form IS 'identifiant du formulaire';
COMMENT ON COLUMN .t_c_synthese_extended.is_valid IS 'Donnée validée';
COMMENT ON COLUMN .t_c_synthese_extended.private_comment IS 'Commentaire privé';
COMMENT ON COLUMN .t_c_synthese_extended.is_hidden IS 'Donnée cachée';

CREATE INDEX i_t_c_synthese_extended_id_sp_source ON .t_c_synthese_extended (id_sp_source);
CREATE INDEX i_t_c_synthese_extended_taxo_group ON .t_c_synthese_extended (taxo_group);
CREATE INDEX i_t_c_synthese_extended_common_name ON .t_c_synthese_extended (common_name);
CREATE INDEX i_t_c_synthese_extended_id_place ON .t_c_synthese_extended (id_place);
CREATE INDEX i_t_c_synthese_extended_is_valid ON .t_c_synthese_extended (is_valid);
CREATE INDEX i_t_c_synthese_extended_is_hidden ON .t_c_synthese_extended (is_hidden);
CREATE INDEX i_t_c_synthese_extended_bird_breed_code_txt ON .t_c_synthese_extended (cast(bird_breed_code AS TEXT));
CREATE INDEX i_t_c_synthese_extended_bird_breed_code ON .t_c_synthese_extended (bird_breed_code);
CREATE INDEX i_t_c_synthese_extended_project_code ON .t_c_synthese_extended (project_code);
)
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.id_sp_source IS 'Code espèce de la source (VisioNature/dbChiroWeb)'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.taxo_group IS 'Groupe taxonomique VisioNature'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.taxo_real IS 'True si Taxon Vrai'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.common_name IS 'Nom vernaculaire'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.pseudo_observer_uid IS 'Identifiant chiffré de l''Observateur pour anonymisation'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.bird_breed_code IS 'Codes "Biolovision" de nidification https://wiki.biolovision.net/Correspondance_codes_atlas'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.bird_breed_status IS 'Statut de nidification simplifié (Nicheur possible, probable, certain) d''après oiso_code_nidif'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.bat_breed_colo IS 'Colonie de reproduction de chauves-souris'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.bat_is_gite IS 'Gite à chauves-souris'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.bat_period IS 'Période du cycle annuel des chauves-souris (hivernage, transit printanier ou automnal, estivage)'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.estimation_code IS 'Code caractérisant le type d''estimation du comptage'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.date_year IS 'Année de l''observation'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.mortality IS 'Est une donnée de mortalité'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.mortality_cause IS 'Cause identifiée de la mortalité'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.export_excluded IS 'A exclure des exports'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.project_code IS 'Code étude'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.juridical_person IS 'Personne morale'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.behaviour IS 'Liste (format ARRAY) des comportements observés'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.geo_accuracy IS 'Précision géographique de la donnée'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.details IS 'Détails de la donnée (format JSON)'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.id_place IS 'Identifiant du lieu-dit'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.place IS 'Nom du Lieu-dit'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.id_form IS 'identifiant du formulaire'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.is_valid IS 'Donnée validée'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.private_comment IS 'Commentaire privé'
;

COMMENT ON COLUMN src_lpodatas.t_c_synthese_extended.is_hidden IS 'Donnée cachée'
;

CREATE INDEX i_t_c_synthese_extended_id_sp_source ON src_lpodatas.t_c_synthese_extended (id_sp_source)
;

CREATE INDEX i_t_c_synthese_extended_taxo_group ON src_lpodatas.t_c_synthese_extended (taxo_group)
;

CREATE INDEX i_t_c_synthese_extended_common_name ON src_lpodatas.t_c_synthese_extended (common_name)
;

CREATE INDEX i_t_c_synthese_extended_id_place ON src_lpodatas.t_c_synthese_extended (id_place)
;

CREATE INDEX i_t_c_synthese_extended_is_valid ON src_lpodatas.t_c_synthese_extended (is_valid)
;

CREATE INDEX i_t_c_synthese_extended_is_hidden ON src_lpodatas.t_c_synthese_extended (is_hidden)
;

CREATE INDEX i_t_c_synthese_extended_bird_breed_code_txt ON src_lpodatas.t_c_synthese_extended (cast(bird_breed_code AS TEXT))
;

CREATE INDEX i_t_c_synthese_extended_bird_breed_code ON src_lpodatas.t_c_synthese_extended (bird_breed_code)
;

CREATE INDEX i_t_c_synthese_extended_project_code ON src_lpodatas.t_c_synthese_extended (project_code)
;


CREATE TABLE src_lpodatas.t_c_rules_diffusion_level
(
id_rule_diffusion_level SERIAL PRIMARY KEY,
cd_nom INT REFERENCES taxonomie.taxref,
id_nomenclature_diffusion_level INTEGER
CONSTRAINT fk_synthese_id_nomenclature_diffusion_level
REFERENCES ref_nomenclatures.t_nomenclatures
ON UPDATE CASCADE
CONSTRAINT check_synthese_diffusion_level
CHECK (ref_nomenclatures.check_nomenclature_type_by_mnemonique(id_nomenclature_diffusion_level,
'NIV_PRECIS'::CHARACTER VARYING)),
meta_create_date TIMESTAMP DEFAULT now(),
meta_update_date TIMESTAMP DEFAULT now()
)
;

CREATE UNIQUE INDEX ON src_lpodatas.t_c_rules_diffusion_level (cd_nom, id_nomenclature_diffusion_level)
;

COMMENT ON TABLE src_lpodatas.t_c_rules_diffusion_level IS 'Table de règle de niveau de diffusion par taxon'
;


CREATE TRIGGER tri_meta_dates_change_synthese
BEFORE INSERT OR UPDATE
ON src_lpodatas.t_c_rules_diffusion_level
FOR EACH ROW
EXECUTE PROCEDURE fct_trg_meta_dates_change()
;


INSERT INTO
src_lpodatas.t_c_rules_diffusion_level(cd_nom, id_nomenclature_diffusion_level)
SELECT
cd_nom
, ref_nomenclatures.get_id_nomenclature('NIV_PRECIS', '4')
FROM
taxonomie.taxref
WHERE
lb_nom IN ('Canis lupus', 'Lynx lynx')
AND cd_nom = cd_ref
;

CREATE UNIQUE INDEX ON src_lpodatas.t_c_rules_diffusion_level (cd_nom, id_nomenclature_diffusion_level)
;

COMMIT
;
16 changes: 11 additions & 5 deletions 01_nomenclatures.sql
Original file line number Diff line number Diff line change
@@ -1,3 +1,11 @@
/*
NOMENCLATURES
-------------
Nomenclatures synonyms management.
*/

BEGIN;

DROP TABLE IF EXISTS ref_nomenclatures.t_c_synonyms CASCADE;

CREATE TABLE ref_nomenclatures.t_c_synonyms (
Expand All @@ -15,7 +23,7 @@ CREATE TABLE ref_nomenclatures.t_c_synonyms (
id_source integer CONSTRAINT fk_t_synonymes_id_source REFERENCES gn_synthese.t_sources
);

ALTER TABLE ref_nomenclatures.t_c_synonyms OWNER TO gnadm;
ALTER TABLE ref_nomenclatures.t_c_synonyms OWNER TO geonatadmin;

COMMENT ON TABLE ref_nomenclatures.t_c_synonyms IS 'Table de correspondances des nomenclatures avec une source tierce';

Expand Down Expand Up @@ -51,8 +59,6 @@ FROM
JOIN ref_nomenclatures.t_nomenclatures ON t_c_synonyms.id_nomenclature = t_nomenclatures.id_nomenclature
JOIN gn_synthese.t_sources ON t_c_synonyms.id_source = t_sources.id_source;

ALTER TABLE ref_nomenclatures.v_c_synonyms OWNER TO gnadm;


/* Function permettant de retrouver l'id_nomenclature à partir des données VisioNature */
DROP FUNCTION IF EXISTS ref_nomenclatures.fct_c_get_synonyms_nomenclature (_type CHARACTER VARYING, _value CHARACTER VARYING);
Expand Down Expand Up @@ -80,6 +86,6 @@ BEGIN
END;
$$;

ALTER FUNCTION ref_nomenclatures.fct_c_get_synonyms_nomenclature (_type CHARACTER VARYING, _value CHARACTER VARYING) OWNER TO gnadm;

COMMENT ON FUNCTION ref_nomenclatures.fct_c_get_synonyms_nomenclature (_type CHARACTER VARYING, _value CHARACTER VARYING) IS 'Fonction de recherche des id_nomenclatures'

COMMIT;
Loading

0 comments on commit 6d21c1c

Please sign in to comment.