create export

This commit is contained in:
Colas Geier 2025-12-03 17:42:22 +01:00
parent 52512463a1
commit ba5ef578d0
2 changed files with 162 additions and 0 deletions

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)