create export

This commit is contained in:
Colas Geier 2025-12-03 17:42:09 +01:00
parent 15d555f3aa
commit 52512463a1

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)