Compare commits

...

3 Commits

Author SHA1 Message Date
ba5ef578d0 create export 2025-12-03 17:42:22 +01:00
52512463a1 create export 2025-12-03 17:42:09 +01:00
15d555f3aa fix doublons export 2025-12-03 17:41:49 +01:00
4 changed files with 409 additions and 7 deletions

View File

@ -1,7 +1,7 @@
from pycen import con_gn
sql = '''
DROP VIEW IF EXISTS gn_exports.v_synthese_sinp_with_metadata_flora_for_gn2pg;
DROP VIEW IF EXISTS gn_exports.v_synthese_sinp_with_metadata_flora_for_gn2pg CASCADE;
CREATE VIEW gn_exports.v_synthese_sinp_with_metadata_flora_for_gn2pg AS
WITH af_actors AS (
@ -10,27 +10,31 @@ CREATE VIEW gn_exports.v_synthese_sinp_with_metadata_flora_for_gn2pg AS
LEFT JOIN utilisateurs.bib_organismes borg ON cafa.id_organism = borg.id_organisme
WHERE borg.uuid_organisme = '5a433bd0-2070-25d9-e053-2614a8c026f8'::uuid
), af AS (
SELECT taf.id_acquisition_framework
SELECT taf.id_acquisition_framework, unique_acquisition_framework_id
FROM gn_meta.t_acquisition_frameworks taf
JOIN af_actors ON af_actors.id_acquisition_framework = taf.id_acquisition_framework
GROUP BY taf.id_acquisition_framework
), ds AS (
SELECT tds.id_dataset,
SELECT tds.id_dataset, tds.unique_dataset_id,
tds.dataset_name AS nom_jdd,
tds.id_acquisition_framework
FROM gn_meta.t_datasets tds
GROUP BY tds.id_dataset, tds.dataset_name
), geo AS (
SELECT "left"(geo_1.area_code::text, 2) AS departement,
geo_1.area_code AS commune,
json_agg(geo_1.area_code) AS commune,
s_1.id_synthese,
st_transform(s_1.the_geom_local, 4326) AS st_transform
FROM ref_geo.l_areas geo_1
JOIN gn_synthese.synthese s_1 ON st_intersects(s_1.the_geom_4326, st_transform(geo_1.geom, 4326))
JOIN gn_synthese.cor_area_synthese USING (id_area)
JOIN gn_synthese.synthese s_1 USING (id_synthese)
WHERE geo_1.id_type = 25
GROUP BY 1,3,4
)
SELECT
af.unique_acquisition_framework_id id_sinp_ca,
ds.nom_jdd AS nom_jdd,
ds.unique_dataset_id id_sinp_jdd,
s.unique_id_sinp_grp AS id_sinp_releve,
occ.id_releve_occtax AS identifiant_releve,
NULL::text AS code_perso_releve,
@ -169,13 +173,13 @@ CREATE VIEW gn_exports.v_synthese_sinp_with_metadata_flora_for_gn2pg AS
LEFT JOIN ref_nomenclatures.t_nomenclatures n19 ON s.id_nomenclature_determination_method = n19.id_nomenclature
LEFT JOIN ref_nomenclatures.t_nomenclatures n20 ON s.id_nomenclature_valid_status = n20.id_nomenclature
LEFT JOIN taxonomie.taxref n21 ON s.cd_nom = n21.cd_nom
JOIN gn_synthese.cor_area_synthese cas ON cas.id_synthese = s.id_synthese
--JOIN gn_synthese.cor_area_synthese cas ON cas.id_synthese = s.id_synthese
-- ADD CEN_38
JOIN gn_synthese.t_sources ts ON ts.id_source = s.id_source
WHERE n21.regne::text = 'Plantae'::text
-- exclision CA ([SICEN] Données anciennes,[TEST] : migration sicen,[SICEN] Hors Etude)
AND ds.id_acquisition_framework NOT IN (53,65,66,1,2,6)
AND ds.id_acquisition_framework NOT IN (53,66,1,2,6)
-- exclision JDD `Observations opportunistes du CEN Isère importé depuis Faune Isère`
AND ds.id_dataset NOT IN (185,377,236)
-- exclision CA (`Gestion de l'Espace Naturel Sensible du Méandre des Oves`, `Gestion de la Réserve Naturelle Nationale de l'Ile de la Platière`, `Gestion des Natura 2000 FR 8201749 « Milieux alluviaux et aquatiques de lÎle de la Platière » et FR 8212012 « Île de la Platière »`, `RNN Platière`

View File

@ -0,0 +1,75 @@
from pycen import con_gn
sql = """
DROP VIEW IF EXISTS gn_exports.v_synthese_sinp_acquisition_flore_with_metadata_for_gn2pg CASCADE;
CREATE OR REPLACE VIEW gn_exports.v_synthese_sinp_acquisition_flore_with_metadata_for_gn2pg AS
WITH af_actors AS
(SELECT cafa.*
FROM gn_meta.cor_acquisition_framework_actor cafa
LEFT JOIN utilisateurs.bib_organismes borg ON cafa.id_organism = borg.id_organisme
--WHERE borg.uuid_organisme = '5a433bd0-2070-25d9-e053-2614a8c026f8'::uuid
--OR borg.uuid_organisme = 'a3c44538-f22a-4134-9e21-28646a73986b'::uuid
), act AS
(SELECT *
FROM crosstab( 'SELECT id_acquisition_framework, id_nomenclature_actor_role, id_organism
FROM gn_meta.cor_acquisition_framework_actor
WHERE id_acquisition_framework NOT IN (1,6)
ORDER BY 1,2' , $$VALUES ('359'::text), ('361')$$ ) AS ct ("id_acquisition_framework" int, "Contact principal" int, "Producteur du jeu de données" int))
SELECT taf.id_acquisition_framework AS id_ca,
taf.unique_acquisition_framework_id AS id_sinp_ca,
taf.acquisition_framework_name AS libelle,
NULL::text AS cadre_acquisition_parent,
taf.acquisition_framework_desc AS description,
taf.keywords AS mots_cles,
ref1.label_default as niveau_territorial,
taf.territory_desc AS description_territoire,
json_agg(ref2.label_default) AS objectifs_cadre_acquisition,
ref4.label_default AS volet_SINP,
ref3.label_default AS type_financement,
taf.target_description AS description_cible,
to_char(taf.meta_create_date, 'DD-MM-YYYY')::date AS date_debut,
NULL::date AS date_fin,
ref5.nom_organisme AS acteur1_organisme,
NULL::text AS acteur1_personne_groupe,
'Contact principal' AS acteur1_type_role,
ref6.nom_organisme AS acteur2_organisme,
NULL::text AS acteur2_personne_groupe,
CASE
WHEN ref6.nom_organisme IS NOT NULL THEN 'Producteur du jeu de données'
ELSE NULL
END AS acteur2_type_role,
NULL::text AS acteur3_organisme,
NULL::text AS acteur3_personne_groupe,
NULL::text AS acteur3_type_role
FROM gn_meta.t_acquisition_frameworks taf
left JOIN af_actors ON af_actors.id_acquisition_framework = taf.id_acquisition_framework
left JOIN gn_meta.cor_acquisition_framework_objectif obj ON obj.id_acquisition_framework = taf.id_acquisition_framework
left JOIN ref_nomenclatures.t_nomenclatures ref1 ON ref1.id_nomenclature = taf.id_nomenclature_territorial_level
JOIN ref_nomenclatures.t_nomenclatures ref2 ON ref2.id_nomenclature = obj.id_nomenclature_objectif
JOIN ref_nomenclatures.t_nomenclatures ref3 ON ref3.id_nomenclature = taf.id_nomenclature_financing_type
left JOIN gn_meta.cor_acquisition_framework_voletsinp sinp ON sinp.id_acquisition_framework = taf.id_acquisition_framework
left JOIN ref_nomenclatures.t_nomenclatures ref4 ON ref4.id_nomenclature = sinp.id_nomenclature_voletsinp
left JOIN act ON act.id_acquisition_framework = taf.id_acquisition_framework
LEFT JOIN utilisateurs.bib_organismes ref5 ON ref5.id_organisme = act."Contact principal"
LEFT JOIN utilisateurs.bib_organismes ref6 ON ref6.id_organisme = act."Producteur du jeu de données"
join gn_exports.v_synthese_sinp_with_metadata_flora_for_gn2pg vsswmffgp on vsswmffgp.id_sinp_ca = taf.unique_acquisition_framework_id
GROUP BY taf.id_acquisition_framework,
taf.unique_acquisition_framework_id,
taf.acquisition_framework_name,
taf.acquisition_framework_desc,
taf.keywords,
ref1.label_default,
taf.territory_desc,
ref4.label_default,
ref3.label_default,
taf.target_description,
to_char(taf.meta_create_date, 'DD-MM-YYYY')::date,
ref5.nom_organisme,
ref6.nom_organisme
order by 1
;
"""
with con_gn.begin() as cnx:
cnx.execute(sql)

View File

@ -0,0 +1,87 @@
from pycen import con_gn
sql = '''
DROP VIEW IF EXISTS gn_exports.v_synthese_sinp_jeu_donnees_flore_with_metadata_for_gn2pg CASCADE;
CREATE VIEW gn_exports.v_synthese_sinp_jeu_donnees_flore_with_metadata_for_gn2pg AS
WITH ds_actors AS (
SELECT cda.id_dataset,
borg.nom_organisme,
cda.id_role,
borg.uuid_organisme,
tro.nom_role,
tro.prenom_role,
borg.email_organisme,
tro.email
FROM gn_meta.cor_dataset_actor cda
LEFT JOIN utilisateurs.bib_organismes borg ON cda.id_organism = borg.id_organisme
LEFT JOIN utilisateurs.t_roles tro ON cda.id_role = tro.id_role
JOIN ref_nomenclatures.t_nomenclatures tn ON cda.id_nomenclature_actor_role = tn.id_nomenclature
-- WHERE borg.uuid_organisme = '5a433bd0-2070-25d9-e053-2614a8c026f8'::uuid
-- OR borg.uuid_organisme = 'a3c44538-f22a-4134-9e21-28646a73986b'::uuid
),
actor AS (
SELECT *
FROM crosstab( 'SELECT id_dataset, id_nomenclature_actor_role, id_organism
FROM gn_meta.cor_dataset_actor
ORDER BY 1,2' ,
$$VALUES ('359'), ('364'), ('365'), ('395')$$ ) AS ct ("id_dataset" int, "Contact principal" int, "Producteur du jeu de données" int, "Point de contact base de données de production" int, "Point de contact pour les métadonnées" int)
),
ds AS (
SELECT distinct tds.id_dataset AS id_jdd,
tds.unique_dataset_id AS id_sinp_jdd,
acq.acquisition_framework_name AS cadre_acquisiton,
tds.dataset_name AS nom_jeu_donnees,
tds.dataset_shortname AS nom_court,
tds.dataset_desc AS description,
ndso.label_default AS objectif,
ncm.label_default AS methode_collecte,
ndo.label_default AS origine_donnees,
nss.label_default AS statut_source,
tds.keywords AS mots_cles,
act1.nom_organisme AS acteur1_organisme,
NULL::text AS acteur1_personne_groupe,
'Contact principal' AS acteur1_type_role,
act2.nom_organisme AS acteur2_organisme,
NULL::text AS acteur2_personne_groupe,
CASE
WHEN act2.nom_organisme IS NOT NULL THEN 'Producteur du jeu de données'
ELSE NULL
END AS acteur2_type_role,
act3.nom_organisme AS acteur3_organisme,
NULL::text AS acteur3_personne_groupe,
CASE
WHEN act3.nom_organisme IS NOT NULL THEN 'Point de contact base de données de production'
ELSE NULL
END AS acteur3_type_role,
act4.nom_organisme AS acteur4_organisme,
NULL::text AS acteur4_personne_groupe,
CASE
WHEN act4.nom_organisme IS NOT NULL THEN 'Point de contact pour les métadonnées'
ELSE NULL
END AS acteur4_type_role
FROM gn_meta.t_datasets tds
left JOIN ds_actors ON ds_actors.id_dataset = tds.id_dataset
left JOIN actor ON actor.id_dataset = tds.id_dataset
JOIN gn_meta.t_acquisition_frameworks acq ON tds.id_acquisition_framework = acq.id_acquisition_framework
LEFT JOIN gn_meta.cor_dataset_territory cdt ON cdt.id_dataset = tds.id_dataset
LEFT JOIN ref_nomenclatures.t_nomenclatures ndt ON tds.id_nomenclature_data_type = ndt.id_nomenclature
LEFT JOIN ref_nomenclatures.t_nomenclatures ncm ON tds.id_nomenclature_collecting_method = ncm.id_nomenclature
LEFT JOIN ref_nomenclatures.t_nomenclatures ndo ON tds.id_nomenclature_data_origin = ndo.id_nomenclature
LEFT JOIN ref_nomenclatures.t_nomenclatures ndso ON tds.id_nomenclature_dataset_objectif = ndso.id_nomenclature
LEFT JOIN ref_nomenclatures.t_nomenclatures nrt ON tds.id_nomenclature_resource_type = nrt.id_nomenclature
LEFT JOIN ref_nomenclatures.t_nomenclatures nss ON tds.id_nomenclature_source_status = nss.id_nomenclature
LEFT JOIN utilisateurs.bib_organismes act1 ON actor."Contact principal" = act1.id_organisme
LEFT JOIN utilisateurs.bib_organismes act2 ON actor."Producteur du jeu de données" = act2.id_organisme
LEFT JOIN utilisateurs.bib_organismes act3 ON actor."Point de contact base de données de production" = act3.id_organisme
LEFT JOIN utilisateurs.bib_organismes act4 ON actor."Point de contact pour les métadonnées" = act4.id_organisme
join gn_exports.v_synthese_sinp_with_metadata_flora_for_gn2pg vsswmffgp on vsswmffgp.id_sinp_jdd = tds.unique_dataset_id
GROUP BY tds.id_dataset, acq.acquisition_framework_name, tds.unique_dataset_id, tds.dataset_name, tds.dataset_shortname, tds.dataset_desc, ndso.label_default, ncm.label_default, ndo.label_default, nss.label_default, ds_actors.nom_organisme, act1.nom_organisme, act2.nom_organisme, act3.nom_organisme, act4.nom_organisme
)
SELECT * FROM ds order by 1
--WHERE acteur1_organisme IN ('Conservatoire despaces naturels Isère')
;
'''
with con_gn.begin() as cnx:
cnx.execute(sql)

View File

@ -0,0 +1,236 @@
from pycen import con_gn
sql = '''
DROP VIEW IF EXISTS gn_exports.v_synthese_zones_humides_isere;
CREATE VIEW gn_exports.v_synthese_zones_humides_isere AS
with habitats as (
SELECT
zh_uuid,
array_agg(lb_code) AS habitats
FROM pr_zh.t_zh
LEFT JOIN pr_zh.cor_zh_cb USING (id_zh)
group by 1 order by 1
), crit_delim as (
SELECT
zh_uuid,
array_agg(ref_nomenclatures.get_nomenclature_label(cor_lim_list.id_lim)) AS crit_delim
FROM pr_zh.t_zh
LEFT JOIN pr_zh.cor_lim_list USING (id_lim_list)
group by 1 order by 1
), esp_fs as (
SELECT
zh_uuid,
array_agg(ref_nomenclatures.get_nomenclature_label(cor_zh_lim_fs.id_lim_fs)) AS crit_esp_fs
FROM pr_zh.t_zh
LEFT JOIN pr_zh.cor_zh_lim_fs USING (id_zh)
group by 1 order by 1
), activ_hum AS (
WITH v_activity AS (
SELECT
id_zh,
array_agg(ref_nomenclatures.get_nomenclature_label(cor_impact_types.id_impact)) impacts
FROM pr_zh.t_activity
LEFT JOIN pr_zh.cor_impact_list USING (id_impact_list)
LEFT JOIN pr_zh.cor_impact_types USING (id_cor_impact_types)
group by 1 order by 1
)
SELECT
zh_uuid,
json_agg(json_build_object(
'activite', ref_nomenclatures.get_nomenclature_label(t_activity.id_activity),
'position', ref_nomenclatures.get_nomenclature_label(t_activity.id_position),
'impact', v_activity.impacts,
'rmq_activ', t_activity.remark_activity
)) AS activ_hum
FROM pr_zh.t_zh
LEFT JOIN pr_zh.t_activity USING (id_zh)
LEFT JOIN v_activity USING (id_zh)
group by zh_uuid order by 1
), inflow as (
SELECT
zh_uuid,
json_agg(json_build_object(
'entree_eau', ref_nomenclatures.get_nomenclature_label(t_inflow.id_inflow),
'perm', ref_nomenclatures.get_nomenclature_label(t_inflow.id_permanance),
'topo', t_inflow.topo
)) AS entree_eau
FROM pr_zh.t_zh
LEFT JOIN pr_zh.t_inflow USING (id_zh)
group by zh_uuid
), outflow as (
SELECT
zh_uuid,
json_agg(json_build_object(
'sortie_eau', ref_nomenclatures.get_nomenclature_label(t_outflow.id_outflow),
'perm', ref_nomenclatures.get_nomenclature_label(t_outflow.id_permanance),
'topo', t_outflow.topo
)) AS sortie_eau
FROM pr_zh.t_zh
LEFT JOIN pr_zh.t_outflow USING (id_zh)
group by zh_uuid
), functions as (
WITH hydro as (
SELECT
zh_uuid,
json_agg(json_build_object(
'fonctions', ref_nomenclatures.get_nomenclature_label(t_functions.id_function),
'qualification', ref_nomenclatures.get_nomenclature_label(t_functions.id_qualification),
'connaissance', ref_nomenclatures.get_nomenclature_label(t_functions.id_knowledge),
'justification', t_functions.justification
)) AS hydro
FROM pr_zh.t_zh
LEFT JOIN pr_zh.t_functions USING (id_zh)
WHERE id_function IN (
SELECT
id_nomenclature
FROM ref_nomenclatures.t_nomenclatures
JOIN ref_nomenclatures.bib_nomenclatures_types bib USING (id_type)
WHERE bib.mnemonique = 'FONCTIONS_HYDRO')
group by zh_uuid
), bio as (
SELECT
zh_uuid,
json_agg(json_build_object(
'fonctions', ref_nomenclatures.get_nomenclature_label(t_functions.id_function),
'qualification', ref_nomenclatures.get_nomenclature_label(t_functions.id_qualification),
'connaissance', ref_nomenclatures.get_nomenclature_label(t_functions.id_knowledge),
'justification', t_functions.justification
)) AS bio
FROM pr_zh.t_zh
LEFT JOIN pr_zh.t_functions USING (id_zh)
WHERE id_function IN (
SELECT
id_nomenclature
FROM ref_nomenclatures.t_nomenclatures
JOIN ref_nomenclatures.bib_nomenclatures_types bib USING (id_type)
WHERE bib.mnemonique = 'FONCTIONS_BIO')
group by zh_uuid
), int_patrim as (
SELECT
zh_uuid,
json_agg(json_build_object(
'fonctions', ref_nomenclatures.get_nomenclature_label(t_functions.id_function),
'qualification', ref_nomenclatures.get_nomenclature_label(t_functions.id_qualification),
'connaissance', ref_nomenclatures.get_nomenclature_label(t_functions.id_knowledge),
'justification', t_functions.justification
)) AS int_patrim
FROM pr_zh.t_zh
LEFT JOIN pr_zh.t_functions USING (id_zh)
WHERE id_function IN (
SELECT
id_nomenclature
FROM ref_nomenclatures.t_nomenclatures
JOIN ref_nomenclatures.bib_nomenclatures_types bib USING (id_type)
WHERE bib.mnemonique = 'INTERET_PATRIM')
group by zh_uuid
), val_socio as (
SELECT
zh_uuid,
json_agg(json_build_object(
'fonctions', ref_nomenclatures.get_nomenclature_label(t_functions.id_function),
'qualification', ref_nomenclatures.get_nomenclature_label(t_functions.id_qualification),
'connaissance', ref_nomenclatures.get_nomenclature_label(t_functions.id_knowledge),
'justification', t_functions.justification
)) AS val_socio
FROM pr_zh.t_zh
LEFT JOIN pr_zh.t_functions USING (id_zh)
WHERE id_function IN (
SELECT
id_nomenclature
FROM ref_nomenclatures.t_nomenclatures
JOIN ref_nomenclatures.bib_nomenclatures_types bib USING (id_type)
WHERE bib.mnemonique = 'VAL_SOC_ECO')
group by zh_uuid
)
SELECT
zh_uuid,
hydro.hydro,
bio.bio,
int_patrim.int_patrim,
val_socio.val_socio
FROM pr_zh.t_zh
LEFT JOIN hydro USING (zh_uuid)
LEFT JOIN bio USING (zh_uuid)
LEFT JOIN int_patrim USING (zh_uuid)
LEFT JOIN val_socio USING (zh_uuid)
--group by zh_uuid
), especes as (
SELECT
zh_uuid,
(select distinct count(vm_flora.cd_nom) from pr_zh.vm_flora where id_zh = t.id_zh) nb_flora,
(select distinct count(vm_vertebrates.cd_nom) from pr_zh.vm_vertebrates where id_zh = t.id_zh) nb_vertebrates,
(select distinct count(vm_invertebrates.cd_nom) from pr_zh.vm_invertebrates where id_zh = t.id_zh) nb_invertebrates
--count(vm_vertebrates.cd_nom) nb_vertebrates,
--count(vm_invertebrates.cd_nom) nb_invertebrates
FROM pr_zh.t_zh t
--GROUP BY zh_uuid
)
SELECT
zh_uuid,
code,
main_name,
CONCAT(crea_role.nom_role, ' ', crea_role.prenom_role) crea_author,
CONCAT(updt_role.nom_role, ' ', updt_role.prenom_role) updt_author,
bib_org.name organisme,
create_date crea_date,
update_date updt_date,
geom,
area surface,
ref_nomenclatures.get_nomenclature_label(id_sdage) sdage,
ref_nomenclatures.get_nomenclature_label(id_sage) sage,
habitats.habitats,
remark_pres descript,
crit_delim.crit_delim,
remark_lim rmq_delilm,
esp_fs.crit_esp_fs,
remark_lim_fs rmq_esp_fs,
ef_area,
v_habref v_hab,
activ_hum.activ_hum,
ref_nomenclatures.get_nomenclature_label(id_thread) bilan_menace,
inflow.entree_eau,
outflow.sortie_eau,
ref_nomenclatures.get_nomenclature_label(id_frequency) freq_sub,
ref_nomenclatures.get_nomenclature_label(id_spread) extend_sub,
ref_nomenclatures.get_nomenclature_label(id_connexion) connex,
ref_nomenclatures.get_nomenclature_label(id_diag_hydro) diag_hydro,
ref_nomenclatures.get_nomenclature_label(id_diag_bio) diag_bio,
functions.hydro,
functions.bio,
functions.int_patrim,
functions.val_socio,
remark_eval_functions eval_fcts,
remark_eval_heritage eval_heritage,
remark_eval_thread eval_menace,
remark_eval_actions eval_actions,
ref_nomenclatures.get_nomenclature_label(id_strat_gestion) strat_gestion,
remark_diag rmq_gestion,
--is_other_inventory,
--is_carto_hab,
--nb_hab,
--total_hab_cover,
especes.nb_flora nb_flora_sp,
especes.nb_vertebrates nb_vertebrate_sp,
especes.nb_invertebrates nb_invertebrate_sp
--remark_is_other_inventory
FROM pr_zh.t_zh
JOIN utilisateurs.t_roles crea_role ON t_zh.create_author = crea_role.id_role
LEFT JOIN utilisateurs.t_roles updt_role ON t_zh.update_author = updt_role.id_role
LEFT JOIN pr_zh.bib_organismes bib_org USING (id_org)
LEFT JOIN habitats USING (zh_uuid)
LEFT JOIN crit_delim USING (zh_uuid)
LEFT JOIN esp_fs USING (zh_uuid)
LEFT JOIN activ_hum USING (zh_uuid)
LEFT JOIN inflow USING (zh_uuid)
LEFT JOIN outflow USING (zh_uuid)
LEFT JOIN functions USING (zh_uuid)
LEFT JOIN especes USING (zh_uuid)
--group BY zh_uuid
WHERE code not like '38CENIS%%' AND code like '38%%'
order by code
;
'''
with con_gn.begin() as cnx:
cnx.execute(sql)