from pycen import con_gn sql = ''' DROP VIEW IF EXISTS gn_exports.export_taxon_unique; CREATE VIEW gn_exports.export_taxon_unique AS WITH af_actors AS ( SELECT cafa.id_acquisition_framework, json_build_object('type_role', CASE WHEN cafa.id_organism IS NOT NULL THEN 'organism'::TEXT WHEN cafa.id_role IS NOT NULL THEN 'role'::TEXT ELSE NULL::TEXT END, 'uuid_actor', coalesce(borg.uuid_organisme, tro.uuid_role), 'cd_nomenclature_actor_role', tn.cd_nomenclature, 'identity', CASE WHEN cafa.id_organism IS NOT NULL THEN json_build_object('organism_name', borg.nom_organisme) WHEN cafa.id_role IS NOT NULL THEN json_build_object('first_name', tro.nom_role, 'last_name', tro.prenom_role) END, 'email', coalesce(borg.email_organisme, tro.email)) AS json_data FROM gn_meta.cor_acquisition_framework_actor cafa LEFT JOIN utilisateurs.bib_organismes borg ON cafa.id_organism = borg.id_organisme LEFT JOIN utilisateurs.t_roles tro ON cafa.id_role = tro.id_role JOIN ref_nomenclatures.t_nomenclatures tn ON cafa.id_nomenclature_actor_role = tn.id_nomenclature), af AS ( SELECT taf.id_acquisition_framework, jsonb_build_object('uuid', taf.unique_acquisition_framework_id, 'name', taf.acquisition_framework_name, 'desc', taf.acquisition_framework_desc, 'start_date', taf.acquisition_framework_start_date, 'end_date', taf.acquisition_framework_end_date, 'initial_closing_date', taf.initial_closing_date, 'territorial_level', ntl.cd_nomenclature, 'financing_type', nft.cd_nomenclature, 'target_description', taf.target_description, 'ecologic_or_geologic_target', taf.ecologic_or_geologic_target, 'actors', json_agg(af_actors.json_data)) AS af_data FROM gn_meta.t_acquisition_frameworks taf JOIN af_actors ON af_actors.id_acquisition_framework = taf.id_acquisition_framework LEFT JOIN ref_nomenclatures.t_nomenclatures ntl ON taf.id_nomenclature_territorial_level = ntl.id_nomenclature LEFT JOIN ref_nomenclatures.t_nomenclatures nft ON taf.id_nomenclature_financing_type = nft.id_nomenclature GROUP BY taf.id_acquisition_framework, taf.acquisition_framework_name, taf.acquisition_framework_desc, taf.acquisition_framework_start_date, taf.acquisition_framework_end_date, taf.initial_closing_date, ntl.cd_nomenclature, nft.cd_nomenclature), ds_actors AS ( SELECT cda.id_dataset, json_build_object('type_role', CASE WHEN cda.id_organism IS NOT NULL THEN 'organism'::TEXT WHEN cda.id_role IS NOT NULL THEN 'role'::TEXT ELSE NULL::TEXT END, 'uuid_actor', coalesce(borg.uuid_organisme, tro.uuid_role), 'cd_nomenclature_actor_role', tn.cd_nomenclature, 'identity', CASE WHEN cda.id_organism IS NOT NULL THEN json_build_object('organism_name', borg.nom_organisme) WHEN cda.id_role IS NOT NULL THEN json_build_object('first_name', tro.nom_role, 'last_name', tro.prenom_role) END, 'email', coalesce(borg.email_organisme, tro.email)) AS json_data 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), ds AS (SELECT tds.id_dataset, tds.id_acquisition_framework, -- tds.additional_data, jsonb_build_object('uuid', tds.unique_dataset_id, 'name', tds.dataset_name, 'desc', tds.dataset_desc, 'shortname', tds.dataset_shortname, 'data_type', ndt.cd_nomenclature, 'collecting_method', ncm.cd_nomenclature, 'data_origin', ndo.cd_nomenclature, 'dataset_objectif', ndso.cd_nomenclature, 'resource_type', nrt.cd_nomenclature, 'source_status', nss.cd_nomenclature, 'territories', array_agg(DISTINCT ref_nomenclatures.get_cd_nomenclature(cdt.id_nomenclature_territory)), 'actors', json_agg(ds_actors.json_data)) AS dataset_data FROM gn_meta.t_datasets tds JOIN ds_actors ON ds_actors.id_dataset = tds.id_dataset 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 GROUP BY tds.id_dataset, tds.id_acquisition_framework, tds.unique_dataset_id, tds.dataset_name, tds.dataset_desc, tds.dataset_shortname, ndt.cd_nomenclature, ncm.cd_nomenclature, ndo.cd_nomenclature, ndso.cd_nomenclature, nrt.cd_nomenclature, nss.cd_nomenclature) SELECT DISTINCT ON (s.cd_nom) s.cd_nom, s.nom_cite, t.regne, t.classe, t.ordre, t.famille, t.sous_famille, t.cd_ref, t.lb_nom, t.nom_complet, t.nom_vern, t.group1_inpn, t.group2_inpn, t.group3_inpn, count(s.cd_nom) occurence FROM gn_synthese.synthese s JOIN ds ON ds.id_dataset = s.id_dataset JOIN af ON ds.id_acquisition_framework = af.id_acquisition_framework LEFT JOIN ref_habitats.habref h ON h.cd_hab = s.cd_hab LEFT JOIN ref_nomenclatures.t_nomenclatures n1 ON s.id_nomenclature_geo_object_nature = n1.id_nomenclature LEFT JOIN ref_nomenclatures.t_nomenclatures n2 ON s.id_nomenclature_grp_typ = n2.id_nomenclature LEFT JOIN ref_nomenclatures.t_nomenclatures n3 ON s.id_nomenclature_behaviour = n3.id_nomenclature LEFT JOIN ref_nomenclatures.t_nomenclatures n4 ON s.id_nomenclature_obs_technique = n4.id_nomenclature LEFT JOIN ref_nomenclatures.t_nomenclatures n5 ON s.id_nomenclature_bio_status = n5.id_nomenclature LEFT JOIN ref_nomenclatures.t_nomenclatures n6 ON s.id_nomenclature_bio_condition = n6.id_nomenclature LEFT JOIN ref_nomenclatures.t_nomenclatures n7 ON s.id_nomenclature_naturalness = n7.id_nomenclature LEFT JOIN ref_nomenclatures.t_nomenclatures n8 ON s.id_nomenclature_exist_proof = n8.id_nomenclature LEFT JOIN ref_nomenclatures.t_nomenclatures n9 ON s.id_nomenclature_diffusion_level = n9.id_nomenclature LEFT JOIN ref_nomenclatures.t_nomenclatures n10 ON s.id_nomenclature_life_stage = n10.id_nomenclature LEFT JOIN ref_nomenclatures.t_nomenclatures n11 ON s.id_nomenclature_sex = n11.id_nomenclature LEFT JOIN ref_nomenclatures.t_nomenclatures n12 ON s.id_nomenclature_obj_count = n12.id_nomenclature LEFT JOIN ref_nomenclatures.t_nomenclatures n13 ON s.id_nomenclature_type_count = n13.id_nomenclature LEFT JOIN ref_nomenclatures.t_nomenclatures n14 ON s.id_nomenclature_sensitivity = n14.id_nomenclature LEFT JOIN ref_nomenclatures.t_nomenclatures n15 ON s.id_nomenclature_observation_status = n15.id_nomenclature LEFT JOIN ref_nomenclatures.t_nomenclatures n16 ON s.id_nomenclature_blurring = n16.id_nomenclature LEFT JOIN ref_nomenclatures.t_nomenclatures n17 ON s.id_nomenclature_source_status = n17.id_nomenclature LEFT JOIN ref_nomenclatures.t_nomenclatures n18 ON s.id_nomenclature_info_geo_type = n18.id_nomenclature 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 JOIN taxonomie.taxref t ON t.cd_nom = s.cd_nom JOIN gn_synthese.t_sources ts ON ts.id_source = s.id_source Group by s.cd_nom, s.nom_cite, t.regne, t.classe, t.ordre, t.famille, t.sous_famille, t.cd_ref, t.lb_nom, t.nom_complet, t.nom_vern, t.group1_inpn, t.group2_inpn, t.group3_inpn ; ''' with con_gn.begin() as cnx: cnx.execute(sql)