Skip to content
Snippets Groups Projects
Commit e8245bd7 authored by Bertrand Gauthier's avatar Bertrand Gauthier
Browse files

Mise à jour des scripts SQL, et documentation.

parent 3cbc90de
No related branches found
No related tags found
No related merge requests found
......@@ -10,103 +10,25 @@
--
-- drop materialized view SYGAL_MV_EMAIL
--/
CREATE MATERIALIZED VIEW SYGAL_MV_EMAIL
refresh complete USING TRUSTED CONSTRAINTS
START WITH SYSDATE NEXT SYSDATE + 1/24/6 as
select sysdate as last_update, tmp.*
from (
select
-- doctorants
to_char(ind.cod_etu) as id,
-- Numero etudiant
ucbn_ldap.etu2mail(ind.cod_etu) as email -- Mail etudiant
from these_hdr_sout ths
join diplome dip on dip.cod_dip = ths.cod_dip
join typ_diplome tpd on tpd.cod_tpd_etb = dip.cod_tpd_etb
join individu ind
on ind.cod_ind = ths.cod_ind --and ind.cod_etu != 21009539 -- Exclusion du compte de test Aaron AAABA
where ths.cod_ths_trv = '1' -- Exclusion des travaux
and dip.cod_tpd_etb in ('39', '40')
and tpd.eta_ths_hdr_drt = 'T' -- Inscription en these
and tpd.tem_sante = 'N' -- Exclusion des theses d exercice
and ind.cod_etu is not null -- oui, oui, ça arrive
union
select *
from (
-- acteurs
with acteur as (
select
ths.cod_ths,
'D' as cod_roj,
ths.cod_per_dir as cod_per,
ths.cod_etb_dir as cod_etb,
ths.cod_cps_dir as cod_cps,
null as tem_rap_recu,
null as cod_roj_compl
from these_hdr_sout ths
where ths.cod_ths_trv = '1' and ths.cod_per_dir is not null
union
select
ths.cod_ths,
'D' as cod_roj,
ths.cod_per_cdr as cod_per,
ths.cod_etb_cdr as cod_etb,
ths.cod_cps_cdr as cod_cps,
null as tem_rap_recu,
null as cod_roj_compl
from these_hdr_sout ths
where ths.cod_ths_trv = '1' and ths.cod_per_cdr is not null
union
select
ths.cod_ths,
'D' as cod_roj,
ths.cod_per_cdr2 as cod_per,
ths.cod_etb_cdr2 as cod_etb,
ths.cod_cps_cdr2 as cod_cps,
null as tem_rap_recu,
null as cod_roj_compl
from these_hdr_sout ths
where ths.cod_ths_trv = '1' and ths.cod_per_cdr2 is not null
union
select
trs.cod_ths,
'R' as cod_roj,
trs.cod_per,
null as cod_etb,
null as cod_cps,
trs.tem_rap_recu,
null as cod_roj_compl
from ths_rap_sou trs
union
select
tjp.cod_ths,
'M' as cod_roj,
tjp.cod_per,
tjp.cod_etb,
tjp.cod_cps,
null as tem_rap_recu,
case when tjp.cod_roj in ('P', 'B', 'A')
then tjp.cod_roj
else null end as cod_roj_compl
from ths_jur_per tjp
)
select distinct
coalesce(regexp_replace(per.num_dos_har_per, '[^0-9]', ''), 'COD_PER_' || act.cod_per) as id,
-- Code Harpege ou Apogee de l acteur
case when per.num_dos_har_per is null
then null
else ucbn_ldap.uid2mail('p' || per.num_dos_har_per) end as email -- Mail acteur
from acteur act
join role_jury roj on roj.cod_roj = act.cod_roj
join personnel per on per.cod_per = act.cod_per
--
-- La vue SYGAL_MV_EMAIL est chargée de fournir les adresses électroniques des individus gravitant autour des thèses.
-- Par défaut, on crée une vue ne ramenant rien.
--
-- Les solutions possibles sont :
-- - modifier la vue SYGAL_MV_EMAIL pour interroger Apogée si les adresses électroniques y sont bien renseignées ;
-- - écrire une vue matérialisée SYGAL_MV_EMAIL interrogeant périodiquement Apogée et un annuaire LDAP
-- (solution actuelle des créateurs de SyGAL, cf. exemple dans `annexe-emails.sql`);
-- - créer une table SYGAL_MV_EMAIL peuplées périodiquement comme bon vous semble.
--
create view SYGAL_MV_EMAIL as
with tmp(LAST_UPDATE, ID, EMAIL) as (
select null, null, null from dual
)
) tmp
where email is not null
select * from tmp where 0=1
/
create view SYGAL_SOURCE as
select
'apogee' as id,
......@@ -116,38 +38,6 @@ create view SYGAL_SOURCE as
from dual
/
create view SYGAL_VARIABLE_MANU as
select
'apogee' as source_id,
'EMAIL_ASSISTANCE' as id,
'EMAIL_ASSISTANCE' as cod_vap,
'Adresse mail de l''assistance utilisateur' as lib_vap,
'assistance-sygal@domaine.fr' as par_vap,
to_date('2017-01-01', 'YYYY-MM-DD') as DATE_DEB_VALIDITE,
to_date('9999-12-31', 'YYYY-MM-DD') as DATE_FIN_VALIDITE
from dual
union all
select
'apogee' as source_id,
'EMAIL_BU' as id,
'EMAIL_BU' as cod_vap,
'Adresse mail de contact de la BU' as lib_vap,
'sygal-bu@domaine.fr' as par_vap,
to_date('2017-01-01', 'YYYY-MM-DD') as DATE_DEB_VALIDITE,
to_date('9999-12-31', 'YYYY-MM-DD') as DATE_FIN_VALIDITE
from dual
union all
select
'apogee' as source_id,
'EMAIL_BDD' as id,
'EMAIL_BDD' as cod_vap,
'Adresse mail de contact du bureau des doctorats' as lib_vap,
'doctorat-sygal@domaine.fr' as par_vap,
to_date('2017-01-01', 'YYYY-MM-DD') as DATE_DEB_VALIDITE,
to_date('9999-12-31', 'YYYY-MM-DD') as DATE_FIN_VALIDITE
from dual
/
create view SYGAL_VARIABLE as
select
'apogee' as source_id, -- Id de la source
......@@ -183,7 +73,7 @@ create view SYGAL_INDIVIDU as
'apogee' as source_id, -- Id de la source
'doctorant' as type,
to_char(ind.cod_etu) as id, -- Numero etudiant
to_char(ind.cod_etu) as supann_id, -- Numero etudiant
to_char(ind.cod_etu) as supann_id,
decode(ind.cod_civ, 1, 'M.', 'Mme') as civ, -- Civilite etudiant
ind.lib_nom_pat_ind as lib_nom_pat_ind, -- Nom de famille etudiant
coalesce(ind.lib_nom_usu_ind, ind.lib_nom_pat_ind) as lib_nom_usu_ind, -- Nom usage etudiant
......@@ -207,7 +97,7 @@ create view SYGAL_INDIVIDU as
and ind.cod_etu is not null -- oui, oui, ça arrive
union
-- acteurs
select * from (
select "SOURCE_ID","TYPE","ID","SUPANN_ID","CIV","LIB_NOM_PAT_IND","LIB_NOM_USU_IND","LIB_PR1_IND","LIB_PR2_IND","LIB_PR3_IND","EMAIL","DATE_NAI_IND","COD_PAY_NAT","LIB_NAT" from (
with acteur as (
select
ths.cod_ths,
......@@ -313,25 +203,20 @@ create view SYGAL_DOCTORANT as
create view SYGAL_THESE as
with inscription_administrative as (
select
iae.cod_ind,
select distinct
ths.cod_ind,
iae.cod_dip,
iae.cod_vrs_vdi,
dip.lib_dip,
max ( iae.cod_anu ) cod_anu_der_iae
from ins_adm_etp iae
iae.cod_vrs_vdi
from these_hdr_sout ths
join ins_adm_etp iae on iae.cod_ind = ths.cod_ind and ( iae.cod_dip, iae.cod_vrs_vdi ) in ( ( ths.cod_dip, ths.cod_vrs_vdi ), ( ths.cod_dip_anc, ths.cod_vrs_vdi_anc ) )
join diplome dip on dip.cod_dip = iae.cod_dip
join typ_diplome tpd on tpd.cod_tpd_etb = dip.cod_tpd_etb
where iae.eta_iae = 'E' -- Inscription administrative non annulee
where ths.cod_ths_trv = '1' -- Exclusion des travaux
and iae.eta_iae = 'E' -- Inscription administrative non annulee
and iae.eta_pmt_iae = 'P' -- Inscription administrative payee
and dip.cod_tpd_etb in ( '39', '40' )
and tpd.eta_ths_hdr_drt = 'T' -- Inscription en these
and tpd.tem_sante = 'N' -- Exclusion des theses d exercice
group by
iae.cod_ind,
iae.cod_dip,
iae.cod_vrs_vdi,
dip.lib_dip
),
hierarchie_structures as (
select
......@@ -351,105 +236,47 @@ create view SYGAL_THESE as
where cod_ths_trv = '1'
and cod_dip_anc is not null
)
select
'apogee' as source_id, -- Id de la source
--
---------- Enregistrement de la these --------
--
ths.cod_ths as id, -- Identifiant de la these
case when ths.eta_ths = 'S' and nvl ( ths.dat_sou_ths, sysdate + 1 ) > sysdate
then 'E' else ths.eta_ths end eta_ths, -- Etat de la these ( E=En cours / A=Abandonnee / S=Soutenue / U=Transferee )
ind.cod_etu doctorant_id, -- Identifiant du doctorant
--iae.cod_dip, -- Code diplome
--iae.cod_vrs_vdi, -- Version de diplome
--nvl ( vdi.lib_web_vdi, iae.lib_dip ) lib_web_vdi, -- Libelle version de diplome
then 'E' else ths.eta_ths end eta_ths, -- Etat de la these (E=En cours, A=Abandonnee, S=Soutenue, U=Transferee)
ind.cod_etu as doctorant_id, -- Identifiant du doctorant
ths.cod_dis, -- Code discipline
dis.lib_int1_dis, -- Libellé discipline
ths.lib_ths, -- Titre de la these
ths.cod_lng, -- Code langue etrangere du titre
--lng.lib_lng, -- Libelle langue etrangere du titre
--lng.lib_nls_lng, -- Parametre Oracle NLS_LANG
--ths.lib_ths_lng, -- Titre de la these dans la langue etrangere
ths.dat_deb_ths, -- Date de 1ere inscription
--iae.cod_anu_der_iae, -- Code annee de derniere inscription
--ths.daa_fin_ths, -- Code annee previsionnelle de soutenance
--ans.lib_anu lib_anu_fin_ths, -- Libelle annee previsionnelle de soutenance
--ths.cod_edo, -- Code ecole doctorale
edo.cod_nat_edo, -- Identifiant national ecole doctorale
--edo.lib_edo, -- Denomination ecole doctorale
--ths.cod_ser, -- Code secteur de recherche principal
--ser.lib_ser, -- Denomination secteur de recherche principal
ths.cod_eqr, -- Code unite de recherche principale
--eqr.lib_eqr, -- Denomination unite de recherche principale
--ths.lib_cmt_ths, -- Informations complementaires sur la these
--
-- ----------------------------- Cotutelle -----------------------------
--
--ths.tem_cot_ths, -- Cotutelle (O/N)
--ths.lib_cmt_cot_ths, -- Descriptif cotutelle
--ths.cod_pay, -- Code pays de cotutelle
null as cod_anu_prm_iae, -- DEPRECATED (cf. SYGAL_THESE_ANNEE_UNIV)
edo.cod_nat_edo as ecole_doct_id, -- Identifiant de l'ecole doctorale
ths.cod_eqr as unite_rech_id, -- Identifiant de l'unité de recherche principale
----------- Cotutelle ----------
pay.lib_pay, -- Denomination pays de cotutelle
--ths.cod_etb cod_etb_cot, -- Code etablissement de cotutelle
nvl ( etb.lib_web_etb, etb.lib_etb ) lib_etb_cot, -- Denomination etablissement de cotutelle
--ths.dat_sign_cnv, -- Date de signature de la convention de cotutelle
ths.tem_avenant, -- Avenant a la convention de cotutelle (O/N)
--ths.tem_etb_sou, -- Soutenance dans l etablissement d inscription (V) ou dans l etablissement de cotutelle (E)
--ths.lib_cmt_compl, -- Info complementaire sur cotutelle
--
-- -------- Abandon ou transferts --------
--
--ths.dat_abandon, -- Date d abandon de la these
--ths.dat_transfert_dep, -- Date de transfert depart
--ths.tem_transfert_arr, -- Transfert arrivee (O/N)
--ths.dat_deb_ths_ori, -- Date de debut de la these dans l etablissement d origine
--ths.cod_etb_origine, -- Code etablissement d origine
--nvl ( ori.lib_web_etb, ori.lib_etb ) lib_etb_origine, -- Denomination etablissement d origine
--
-- -------- Expertise des rapporteurs --------
--
--ths.dat_des_rap_ths, -- Date de designation des rapporteurs
--
-- -------- Organisation de la soutenance --------
--
--ths.duree_ths, -- Duree de la these en mois
--ths.eta_duree_ths, -- Etat de la duree de la these ( M=Modifiee? / C=Calculee? )
------- Organisation de la soutenance ------
ths.dat_prev_sou, -- Date previsionnelle de soutenance
ths.tem_sou_aut_ths, -- Soutenance autorisee (O/N/null)
ths.dat_aut_sou_ths, -- Date d autorisation de soutenance
--ths.lib_cmt_sou_aut_ths, -- Commentaire associe a la non autorisation de soutenance
--ths.lib_cmt_leu_sou_ths, -- Lieu de la soutenance
--ths.cod_etb_sou, -- Code etablissement du lieu de soutenance
--nvl ( sou.lib_web_etb, sou.lib_etb ) lib_etb_sou, -- Denomination etablissement du lieu de soutenance
ths.dat_sou_ths, -- Date de soutenance de la these
--ths.hh_sou_ths, -- Heure de soutenance (hh)
--ths.mm_sou_ths, -- Heure de soutenance (mi)
--cmp.cod_cmp, -- Code composante
--cmp.lib_web_cmp, -- Libelle composante
--ths.tem_aut_etb_sou_ths, -- Soutenance dans autre etablissement si cotutelle (O/N)
--
---------- Confidentialite --------
--
--ths.tem_pub_sou_ths, -- Soutenance publique (O/N)
--ths.lib_cmt_pub_sou_ths, -- Commentaire associe a la confidentialite de la these
ths.dat_fin_cfd_ths, -- Date de fin de confidentialite de la these
--
---------- Jury et resultats --------
--
--ths.dat_des_jur_ths, -- Date de designation du jury
-- rvi.cod_anu cod_anu_rvi, -- Code annee universitaire du resultat
--anr.lib_anu lib_anu_rvi, -- Libelle annee universitaire du resultat
tre.cod_neg_tre, -- Resultat positif (1) ou non (0)
--rvi.cod_tre, -- Code resultat
--tre.lib_tre, -- Libelle resultat
--rvi.cod_men, -- Code mention
--men.lib_men, -- Libelle mention
--ths.tem_lab_eur_ths, -- Label europeen (O/N)
ths.eta_rpd_ths, -- Reproduction de la these ( O=Oui / C=Oui avec corrections / N=Non )
decode(ths.eta_rpd_ths, 'N', 'obligatoire', 'C', 'facultative', null) as correction_possible
--ths.tem_cor_ths, -- Corrections effectuees (O/N)
--ths.tem_pv_transmis, -- PV de soutenance transmis (O/N)
--ths.tem_rap_transmis, -- Rapport de soutenance transmis (O/N)
--ths.tem_stop_mvt_abes -- Aucun mouvement ne doit etre genere vers l ABES (O/N)
decode(ths.eta_rpd_ths,
'N', 'obligatoire',
'C', 'facultative',
null) as correction_possible -- Témoin de corrections attendues
from inscription_administrative iae
join individu ind on ind.cod_ind = iae.cod_ind
join version_diplome vdi on vdi.cod_dip = iae.cod_dip and vdi.cod_vrs_vdi = iae.cod_vrs_vdi
......@@ -471,8 +298,9 @@ create view SYGAL_THESE as
left join etablissement sou on sou.cod_etb = ths.cod_etb_sou
left join etablissement ori on ori.cod_etb = ths.cod_etb_origine
left join langue lng on lng.cod_lng = ths.cod_lng
where ths.cod_ths_trv = '1' -- Exclusion des travaux
and anc.cod_dip_anc is null
where
ths.cod_ths_trv = '1' and -- Exclusion des travaux
anc.cod_dip_anc is null
/
create view SYGAL_STRUCTURE as
......@@ -785,6 +613,7 @@ create view SYGAL_ACTEUR as
roj.cod_roj as role_id, -- Identifiant du rôle
cast(act.cod_roj_compl as varchar2(1 char)) as cod_roj_compl, -- Code du complement sur le role dans le jury
rjc.lib_roj as lib_roj_compl, -- Libelle du complement sur le role dans le jury
act.cod_per,
coalesce(
regexp_replace(per.num_dos_har_per,'[^0-9]',''),
'COD_PER_'||act.cod_per
......@@ -806,26 +635,47 @@ create view SYGAL_ACTEUR as
/
create view SYGAL_FINANCEMENT as
select distinct
tfi.cod_seq_tfi as id, -- Numero de sequence du financement
with inscription_admin as (
select
iae.cod_ind,
iae.cod_dip,
iae.cod_vrs_vdi,
dip.lib_dip,
min ( iae.cod_anu ) cod_anu_prm_iae
from ins_adm_etp iae
join diplome dip on dip.cod_dip = iae.cod_dip
join typ_diplome tpd on tpd.cod_tpd_etb = dip.cod_tpd_etb
where iae.eta_iae = 'E' -- Inscription administrative non annulee
and iae.eta_pmt_iae = 'P' -- Inscription administrative payee
and dip.cod_tpd_etb in ( '39', '40' )
and tpd.eta_ths_hdr_drt = 'T' -- Inscription en these
and tpd.tem_sante = 'N' -- Exclusion des theses d exercice
group by
iae.cod_ind,
iae.cod_dip,
iae.cod_vrs_vdi,
dip.lib_dip
)
select
min ( tfi.cod_seq_tfi ) as id, -- Premier numero de sequence du financement
'apogee' as source_id,
tfi.cod_ths as these_id,
tfi.cod_anu as annee_id, -- Identifiant de l annee universitaire (ex. 2018 pour 2018/2019)
min ( nvl ( tfi.cod_anu, iae.cod_anu_prm_iae ) ) as annee_id, -- Identifiant de l annee universitaire (ex. 2018 pour 2018/2019)
tfi.cod_ofi as origine_financement_id,
tfi.compl_tfi as complement_financement,
listagg ( tfi.compl_tfi, ' / ' ) within group ( order by tfi.cod_ths, tfi.cod_ofi, tfi.quotite_tfi, nvl ( tfi.cod_anu, iae.cod_anu_prm_iae ), tfi.cod_seq_tfi ) as complement_financement,
tfi.quotite_tfi as quotite_financement,
tfi.dat_deb_tfi as date_debut_financement,
tfi.dat_fin_tfi as date_fin_financement
from these_hdr_sout ths
join diplome dip on dip.cod_dip = ths.cod_dip
join typ_diplome tpd on tpd.cod_tpd_etb = dip.cod_tpd_etb
min ( tfi.dat_deb_tfi ) as date_debut_financement,
max ( tfi.dat_fin_tfi ) as date_fin_financement
from inscription_admin iae
join these_hdr_sout ths on ths.cod_ind = iae.cod_ind and ths.cod_dip = iae.cod_dip and ths.cod_vrs_vdi = iae.cod_vrs_vdi
join ths_financement tfi on tfi.cod_ths = ths.cod_ths
join origine_financement ofi on ofi.cod_ofi = tfi.cod_ofi
where ths.cod_ths_trv = '1' -- Exclusion des travaux
and tpd.eta_ths_hdr_drt = 'T' -- Inscription en these
and tpd.tem_sante = 'N' -- Exclusion des theses d exercice
and ofi.tem_en_sve_ofi = 'O' -- Exclusion des anciens codes des origines de financements;
and tfi.cod_anu is not null
and ofi.tem_en_sve_ofi = 'O' -- Exclusion des anciens codes des origines de financements
group by
tfi.cod_ths,
tfi.cod_ofi,
tfi.quotite_tfi
/
create view SYGAL_ORIGINE_FINANCEMENT as
......@@ -950,3 +800,34 @@ create view SYGAL_TITRE_ACCES as
where
tac.titre_acces_interne_externe is not null
/
create view SYGAL_THESE_ANNEE_UNIV as
with old_these as (
select distinct
cod_ind,
cod_dip_anc,
cod_vrs_vdi_anc,
'A' eta_ths
from these_hdr_sout
where cod_ths_trv = '1'
and cod_dip_anc is not null
)
select distinct
'apogee' as source_id,
ths.cod_ths || '_' || iae.cod_anu as id,
ths.cod_ths as these_id,
iae.cod_anu as annee_univ
from these_hdr_sout ths
left join old_these old on old.cod_ind = ths.cod_ind and old.cod_dip_anc = ths.cod_dip and old.cod_vrs_vdi_anc = ths.cod_vrs_vdi and old.eta_ths = ths.eta_ths
join diplome dip on dip.cod_dip = ths.cod_dip
join typ_diplome tpd on tpd.cod_tpd_etb = dip.cod_tpd_etb
join ins_adm_etp iae on iae.cod_ind = ths.cod_ind and ( iae.cod_dip, iae.cod_vrs_vdi ) in ( ( ths.cod_dip, ths.cod_vrs_vdi ), ( ths.cod_dip_anc, ths.cod_vrs_vdi_anc ) )
join individu ind on ind.cod_ind = iae.cod_ind
where ths.cod_ths_trv = '1' -- Exclusion des travaux
and old.cod_dip_anc is null
and dip.cod_tpd_etb in ( '39', '40' )
and tpd.eta_ths_hdr_drt = 'T' -- Diplome de type these
and tpd.tem_sante = 'N' -- Exclusion des theses d exercice
and iae.eta_iae = 'E' -- Inscription administrative non annulee
and iae.eta_pmt_iae = 'P'
/
--
--
-- SyGAL
-- =====
--
-- Web Service d'import de données
-- -------------------------------
--
-- Vues Apogée propre à votre établissement, à personnaliser.
--
--
-- Vue fournissant les "variables d'environnement" requis par SyGAL :
-- - Adresse mail de l'assistance utilisateur
-- - Adresse mail de contact de la BU
-- - Adresse mail de contact du bureau des doctorats
--
create or replace view SYGAL_VARIABLE_MANU as
select
'apogee' as source_id,
'EMAIL_ASSISTANCE' as id,
'EMAIL_ASSISTANCE' as cod_vap,
'Adresse mail de l''assistance utilisateur' as lib_vap,
'assistance-sygal@univ.fr' as par_vap, -----------------------------> à personnaliser
to_date('2017-01-01', 'YYYY-MM-DD') as DATE_DEB_VALIDITE,
to_date('9999-12-31', 'YYYY-MM-DD') as DATE_FIN_VALIDITE
from dual
union all
select
'apogee' as source_id,
'EMAIL_BU' as id,
'EMAIL_BU' as cod_vap,
'Adresse mail de contact de la BU' as lib_vap,
'bu@univ.fr' as par_vap, ------------------------------------------> à personnaliser
to_date('2017-01-01', 'YYYY-MM-DD') as DATE_DEB_VALIDITE,
to_date('9999-12-31', 'YYYY-MM-DD') as DATE_FIN_VALIDITE
from dual
union all
select
'apogee' as source_id,
'EMAIL_BDD' as id,
'EMAIL_BDD' as cod_vap,
'Adresse mail de contact du bureau des doctorats' as lib_vap,
'bdd@univ.fr' as par_vap, -----------------------------------------> à personnaliser
to_date('2017-01-01', 'YYYY-MM-DD') as DATE_DEB_VALIDITE,
to_date('9999-12-31', 'YYYY-MM-DD') as DATE_FIN_VALIDITE
from dual
/
--
-- Vue traduisant les codes rôles en usage dans votre établissement vers les codes compris par SyGAL.
--
create or replace view SYGAL_ROLE_TR as
select 'A', 'A' from dual union -- A : Membre absent
select 'B', 'B' from dual union -- B : Co-encadrant
select 'C', 'C' from dual union -- C : Chef de laboratoire
select 'D', 'D' from dual union -- D : Directeur de thèse
select 'K', 'K' from dual union -- K : Co-directeur de thèse
select 'M', 'M' from dual union -- M : Membre du jury
select 'P', 'P' from dual union -- P : Président du jury
select 'R', 'R' from dual -- R : Rapporteur du jury
/
--
--
-- SyGAL
-- =====
--
-- Web Service d'import de données
-- -------------------------------
--
-- Vue matérialisée interrogeant Apogée et l'annuaire LDAP (grâce au package UCBN_LDAP) pour obtenir
-- les adresses électroniques.
--
-- drop materialized view SYGAL_MV_EMAIL
--/
CREATE MATERIALIZED VIEW SYGAL_MV_EMAIL
refresh complete USING TRUSTED CONSTRAINTS
START WITH SYSDATE NEXT SYSDATE + 1/24/6 as
select sysdate as last_update, tmp.*
from (
select
-- doctorants
to_char(ind.cod_etu) as id,
-- Numero etudiant
ucbn_ldap.etu2mail(ind.cod_etu) as email -- Mail etudiant
from these_hdr_sout ths
join diplome dip on dip.cod_dip = ths.cod_dip
join typ_diplome tpd on tpd.cod_tpd_etb = dip.cod_tpd_etb
join individu ind
on ind.cod_ind = ths.cod_ind --and ind.cod_etu != 21009539 -- Exclusion du compte de test Aaron AAABA
where ths.cod_ths_trv = '1' -- Exclusion des travaux
and dip.cod_tpd_etb in ('39', '40')
and tpd.eta_ths_hdr_drt = 'T' -- Inscription en these
and tpd.tem_sante = 'N' -- Exclusion des theses d exercice
and ind.cod_etu is not null -- oui, oui, ça arrive
union
select *
from (
-- acteurs
with acteur as (
select
ths.cod_ths,
'D' as cod_roj,
ths.cod_per_dir as cod_per,
ths.cod_etb_dir as cod_etb,
ths.cod_cps_dir as cod_cps,
null as tem_rap_recu,
null as cod_roj_compl
from these_hdr_sout ths
where ths.cod_ths_trv = '1' and ths.cod_per_dir is not null
union
select
ths.cod_ths,
'D' as cod_roj,
ths.cod_per_cdr as cod_per,
ths.cod_etb_cdr as cod_etb,
ths.cod_cps_cdr as cod_cps,
null as tem_rap_recu,
null as cod_roj_compl
from these_hdr_sout ths
where ths.cod_ths_trv = '1' and ths.cod_per_cdr is not null
union
select
ths.cod_ths,
'D' as cod_roj,
ths.cod_per_cdr2 as cod_per,
ths.cod_etb_cdr2 as cod_etb,
ths.cod_cps_cdr2 as cod_cps,
null as tem_rap_recu,
null as cod_roj_compl
from these_hdr_sout ths
where ths.cod_ths_trv = '1' and ths.cod_per_cdr2 is not null
union
select
trs.cod_ths,
'R' as cod_roj,
trs.cod_per,
null as cod_etb,
null as cod_cps,
trs.tem_rap_recu,
null as cod_roj_compl
from ths_rap_sou trs
union
select
tjp.cod_ths,
'M' as cod_roj,
tjp.cod_per,
tjp.cod_etb,
tjp.cod_cps,
null as tem_rap_recu,
case when tjp.cod_roj in ('P', 'B', 'A')
then tjp.cod_roj
else null end as cod_roj_compl
from ths_jur_per tjp
)
select distinct
coalesce(regexp_replace(per.num_dos_har_per, '[^0-9]', ''), 'COD_PER_' || act.cod_per) as id,
-- Code Harpege ou Apogee de l acteur
case when per.num_dos_har_per is null
then null
else ucbn_ldap.uid2mail('p' || per.num_dos_har_per) end as email -- Mail acteur
from acteur act
join role_jury roj on roj.cod_roj = act.cod_roj
join personnel per on per.cod_per = act.cod_per
)
) tmp
where email is not null
/
\ No newline at end of file
--
--
-- SyGAL
-- =====
--
-- Web Service d'import de données
-- -------------------------------
--
-- Vues Physalis propre à votre établissement, à personnaliser.
--
/*
Néant
*/
0% Loading or .
You are about to add 0 people to the discussion. Proceed with caution.
Please register or to comment