Python_scripts/5_GEONATURE/EXPORT/meta_ca_flore_sinp.py
2025-12-03 17:42:22 +01:00

75 lines
3.7 KiB
Python

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)