/* Création de la table CONTACT */ CREATE TABLE report.f_contact_v2 ( ctc_id int4 NULL, cqu_rang int4 NULL, dos_id int4 NULL, cqu_dt_deb timestamp NULL, cqu_dt_fin timestamp NULL, ctc_dt_reception timestamp NULL, cqu_duree int4 NULL, age_id int4 NULL, mtf_id int4 NULL, mtfd_id int4 NULL, ttr_code varchar(10) NULL, tfl_id int4 NULL, act_id int4 NULL, ref_id_carac int4 NULL, tae_id_traite int4 NULL, domaine bpchar(50) NULL, enseigne bpchar(50) NULL, univers bpchar(50) NULL, CONSTRAINT const_ctc_id_cqu_rang UNIQUE (ctc_id, cqu_rang) ); CREATE INDEX idx_ctc_id_cqu_rang ON report.f_contact_v2 USING btree (ctc_id, cqu_rang); ALTER TABLE report.f_contact_v2 ADD CONSTRAINT const_ctc_id_cqu_rang UNIQUE (ctc_id, cqu_rang); /* Création de la table TACHE */ CREATE TABLE report.f_task_v2 ( tae_id int4 NULL, dos_id int4 NULL, ref_id_statut numeric(8) NULL, tae_date_a_faire timestamp NULL, tae_date_der_etat timestamp NULL, tae_date_fin timestamp NULL, tae_dt_maj timestamp NULL, cqu_dt_deb timestamp NULL, cqu_dt_fin timestamp NULL, cqu_duree int8 NULL, ref_id_carac numeric(8) NULL, act_id int4 NULL, tfl_id int8 NULL, dta_id numeric(9) NULL, ttr_code varchar(10) NULL, mtf_id int4 NULL, mtfd_id int4 NULL, mtfdm_id int4 NULL, age_id int4 NULL, domaine varchar NULL, enseigne varchar NULL, univers varchar NULL, tae_date_creation timestamp NULL, CONSTRAINT const_tar_id UNIQUE (tae_id) ); CREATE INDEX idx_tae_id ON report.f_task_v2 USING btree (tae_id); ALTER TABLE report.f_task_v2 ADD CONSTRAINT const_tar_id UNIQUE (tae_id); /* Création de la table dossier */ CREATE TABLE report.f_dossier_v2 ( id serial4 NOT NULL, date_insert timestamp NULL, date_max_maj timestamp NULL, dos_id int4 NULL, dos_numero varchar(250) NULL, type_dossier varchar(250) NULL, statut_dossier varchar(250) NULL, dos_date_creation date NULL, dos_date_creation_heure timestamp NULL, dos_date_cloture date NULL, dos_date_cloture_heure timestamp NULL, motif_dossier_1 varchar(250) NULL, motif_dossier_2 varchar(250) NULL, motif_dossier_3 varchar(250) NULL, type_fiche varchar(250) NULL, id_entite int4 NULL, nom_client varchar(250) NULL, prenom_client varchar(250) NULL, id_der_qualif varchar(250) NULL, activite_der_qualif varchar(250) NULL, flux_der_qualif varchar(250) NULL, type_traitement_der_qualif varchar(250) NULL, id_agent_der_qualif int4 NULL, agent_der_qualif varchar(250) NULL, equipe_der_qualif varchar(250) NULL, motif_ttr_1_der_qualif varchar(250) NULL, motif_ttr_2_der_qualif varchar(250) NULL, motif_ttr_3_der_qualif varchar(250) NULL, action_der_qualif varchar(250) NULL, date_fin_der_qualif timestamp NULL, motif_dde_1_der_qualif varchar(250) NULL, motif_dde_2_der_qualif varchar(250) NULL, motif_dde_3_der_qualif varchar(250) NULL, univers varchar(250) NULL, enseigne varchar(250) NULL, domaine varchar(250) NULL, nb_contact int4 NULL, nb_qualif int4 NULL, dmt int4 NULL, dos_date_derniere_maj timestamp NULL, max_cqu_dt_fin timestamp NULL, CONSTRAINT const_dos_id UNIQUE (dos_id) ); CREATE INDEX idx_dos_id ON report.f_dossier_v2 USING btree (dos_id); ALTER TABLE report.f_dossier_v2 ADD CONSTRAINT const_dos_id UNIQUE (dos_id); /* Création d'une table de logs afin d'historiser les eventuelles erreurs et les lancements */ CREATE TABLE report.etl_logs ( load_id int4 DEFAULT nextval('report.etl_logs_js_load_id_seq'::regclass) NOT NULL, table_name varchar(55) NULL, profondeur int4 NULL, exec_start timestamp NULL, exec_end timestamp NULL, status varchar(10) NULL, nb_rows int4 NULL, error_message varchar(255) NULL, CONSTRAINT etl_logs_js_pkey PRIMARY KEY (load_id) ); CREATE SEQUENCE report.etl_logs_js_load_id_seq INCREMENT BY 1 MINVALUE 1 MAXVALUE 2147483647 START 1 CACHE 1 NO CYCLE; CREATE SEQUENCE report.etl_logs_load_id_seq INCREMENT BY 1 MINVALUE 1 MAXVALUE 2147483647 START 1 CACHE 1 NO CYCLE; /* Fonction d'écriture de logs*/ CREATE OR REPLACE FUNCTION report.sp_writelogs(p_materialized_view character varying, p_profondeur integer, p_exec_start timestamp without time zone, p_exec_end timestamp without time zone, p_status character varying, p_nb_rows integer, p_error_message character varying) RETURNS void LANGUAGE plpgsql AS $function$ BEGIN INSERT INTO report.etl_logs ( table_name, profondeur, exec_start, exec_end, status, nb_rows, error_message ) VALUES ( p_MATERIALIZED_VIEW, p_PROFONDEUR, p_EXEC_START, p_EXEC_END, p_STATUS, p_NB_ROWS, p_ERROR_MESSAGE ); END; $function$ ; /* Fonction de mise à jour des contacts */ CREATE OR REPLACE FUNCTION report.refresh_contact(v_profondeur integer) RETURNS void LANGUAGE plpgsql AS $function$ DECLARE v_exec_start TIMESTAMP; v_exec_end TIMESTAMP; v_nb_rows INT; v_status VARCHAR(10); -- v_type_exec VARCHAR(1); v_error_message VARCHAR(255); v_date_threshold DATE; BEGIN -- Heure de début d'exécution v_exec_start := clock_timestamp(); v_status := 'success'; -- Valeur par défaut du statut v_date_threshold := CURRENT_DATE - (v_profondeur * INTERVAL '1 day'); -- Insérer les nouvelles données INSERT INTO report.f_contact_v2 ( ctc_id, cqu_rang, dos_id, cqu_dt_deb, cqu_dt_fin, ctc_dt_reception, cqu_duree, age_id, mtf_id, mtfd_id, ttr_code, tfl_id, act_id, ref_id_carac, tae_id_traite, domaine, enseigne, univers ) WITH task AS ( SELECT ref_id_carac, tae_id, cqu_rang_traite_par, ctc_id_traite_par, RANK() OVER (PARTITION BY ctc_id_traite_par, cqu_rang_traite_par ORDER BY tae_id DESC) AS rk FROM s_tache ) SELECT contact.ctc_id, contact.cqu_rang, contact.dos_id, contact.cqu_dt_deb, contact.cqu_dt_fin, contact.ctc_dt_reception, contact.cqu_duree, contact.age_id, contact.mtf_id, d.mtfd_id AS mtfd_id, contact.ttr_code, contact.tfl_id, contact.act_id, s_tache.ref_id_carac::integer, s_tache.tae_id AS tae_id_traite, contact_domaine(contact.ctc_id, contact.cqu_rang)::character(50) AS domaine, contact_enseigne(contact.ctc_id, contact.cqu_rang)::character(50) AS enseigne, contact_univers(contact.ctc_id, contact.cqu_rang)::character(50) AS univers FROM s_contact_simple contact LEFT JOIN task s_tache ON contact.cqu_rang = s_tache.cqu_rang_traite_par AND contact.ctc_id = s_tache.ctc_id_traite_par AND s_tache.rk = 1 LEFT JOIN s_dos_contact dc ON contact.ctc_id = dc.ctc_id AND contact.cqu_rang = dc.cqu_rang AND contact.dos_id = dc.dos_id LEFT JOIN s_dos_dossier d ON d.dos_id = dc.dos_id WHERE COALESCE(contact.cqu_dt_deb, '2000-01-01') > v_date_threshold or contact.cqu_dt_fin > v_date_threshold or COALESCE(contact.ctc_dt_reception , '2000-01-01') > v_date_threshold ON CONFLICT (ctc_id, cqu_rang) DO UPDATE SET dos_id = EXCLUDED.dos_id, cqu_dt_deb = EXCLUDED.cqu_dt_deb, cqu_dt_fin = EXCLUDED.cqu_dt_fin, ctc_dt_reception = EXCLUDED.ctc_dt_reception, cqu_duree = EXCLUDED.cqu_duree, age_id = EXCLUDED.age_id, mtf_id = EXCLUDED.mtf_id, mtfd_id = EXCLUDED.mtfd_id, ttr_code = EXCLUDED.ttr_code, tfl_id = EXCLUDED.tfl_id, act_id = EXCLUDED.act_id, ref_id_carac = EXCLUDED.ref_id_carac, tae_id_traite = EXCLUDED.tae_id_traite, domaine = EXCLUDED.domaine, enseigne = EXCLUDED.enseigne, univers = EXCLUDED.univers; -- Nombre de lignes insérées GET DIAGNOSTICS v_nb_rows = ROW_COUNT; -- Prendre l'heure de fin de rafraîchissement v_exec_end := clock_timestamp(); -- Journaliser les informations d'exécution dans les logs PERFORM report.sp_writelogs('f_contact', v_profondeur, v_exec_start, v_exec_end, v_status, v_nb_rows, NULL); EXCEPTION WHEN OTHERS THEN v_status := 'error'; v_error_message := SQLERRM; v_exec_end := clock_timestamp(); -- Enregistrer le moment de l'erreur -- Journaliser l'erreur dans les logs PERFORM report.sp_writelogs('f_contact', v_profondeur, v_exec_start, v_exec_end, v_status, 0, v_error_message); END; $function$ ; /* Fonction de mise à jour des taches */ CREATE OR REPLACE FUNCTION report.refresh_task(v_profondeur integer) RETURNS void LANGUAGE plpgsql AS $function$ DECLARE v_exec_start TIMESTAMP; v_exec_end TIMESTAMP; v_nb_rows INT; v_status VARCHAR(10); -- v_type_exec VARCHAR(1); v_error_message VARCHAR(255); v_date_threshold DATE; BEGIN -- Heure de début d'exécution v_exec_start := clock_timestamp(); v_status := 'success'; -- Valeur par défaut du statut v_date_threshold := CURRENT_DATE - (v_profondeur * INTERVAL '1 day'); -- Insérer les nouvelles données INSERT INTO report.f_task_v2 ( tae_id, dos_id, ref_id_statut, tae_date_a_faire, tae_date_der_etat, tae_date_fin, tae_dt_maj, cqu_dt_deb, cqu_dt_fin, cqu_duree, ref_id_carac, act_id, tfl_id, dta_id, ttr_code, mtf_id, mtfd_id, mtfdm_id, age_id, domaine, enseigne, univers, tae_date_creation ) WITH contact_dmt AS ( SELECT ctc_id, SUM(cqu_duree) AS cqu_duree FROM s_contact_simple GROUP BY ctc_id ), contact_deb AS ( SELECT ctc_id, cqu_dt_deb FROM s_contact_simple WHERE cqu_rang = 1 ), contact_fin AS ( SELECT ctc_id, cqu_rang, act_id, mtf_id, mtfdm_id, age_id, cqu_dt_fin FROM s_contact_simple ) SELECT tache.tae_id, tache.dos_id, ref_id_statut, tae_date_a_faire, tae_date_der_etat, tae_date_fin, tae_dt_maj, contact_deb.cqu_dt_deb, contact_fin.cqu_dt_fin, contact_dmt.cqu_duree, ref_id_carac, contact_fin.act_id, tache.tfl_id, dta_id, contact.ttr_code, contact_fin.mtf_id, mtfd_id, contact_fin.mtfdm_id, contact_fin.age_id, tache_domaine(tache.tae_id) AS domaine, tache_enseigne(tache.tae_id) AS enseigne, tache_univers(tache.tae_id) AS univers, tae_date_creation FROM s_tache AS tache LEFT JOIN s_contact_simple contact ON contact.cqu_rang = tache.cqu_rang_traite_par AND contact.ctc_id = tache.ctc_id_traite_par LEFT JOIN contact_dmt ON tache.ctc_id_traite_par = contact_dmt.ctc_id LEFT JOIN contact_deb ON tache.ctc_id_traite_par = contact_deb.ctc_id AND tache.cqu_rang_traite_par = 1 LEFT JOIN contact_fin ON tache.ctc_id_traite_par = contact_fin.ctc_id AND tache.cqu_rang_traite_par = contact_fin.cqu_rang LEFT JOIN s_dos_dossier d ON d.dos_id = tache.dos_id WHERE tae_dt_maj > v_date_threshold::timestamp OR tae_date_der_etat > v_date_threshold::timestamp OR tae_date_creation > v_date_threshold::timestamp OR (ref_id_statut <> 6 AND tae_date_creation < v_date_threshold::timestamp) ON CONFLICT (tae_id) DO UPDATE SET dos_id = EXCLUDED.dos_id, ref_id_statut = EXCLUDED.ref_id_statut, tae_date_a_faire = EXCLUDED.tae_date_a_faire, tae_date_der_etat = EXCLUDED.tae_date_der_etat, tae_date_fin = EXCLUDED.tae_date_fin, tae_dt_maj = EXCLUDED.tae_dt_maj, cqu_dt_deb = EXCLUDED.cqu_dt_deb, cqu_dt_fin = EXCLUDED.cqu_dt_fin, cqu_duree = EXCLUDED.cqu_duree, ref_id_carac = EXCLUDED.ref_id_carac, act_id = EXCLUDED.act_id, tfl_id = EXCLUDED.tfl_id, dta_id = EXCLUDED.dta_id, ttr_code = EXCLUDED.ttr_code, mtf_id = EXCLUDED.mtf_id, mtfd_id = EXCLUDED.mtfd_id, mtfdm_id = EXCLUDED.mtfdm_id, age_id = EXCLUDED.age_id, domaine = EXCLUDED.domaine, enseigne = EXCLUDED.enseigne, univers = EXCLUDED.univers, tae_date_creation = EXCLUDED.tae_date_creation; -- Nombre de lignes insérées GET DIAGNOSTICS v_nb_rows = ROW_COUNT; -- Prendre l'heure de fin de rafraîchissement v_exec_end := clock_timestamp(); -- Journaliser les informations d'exécution dans les logs PERFORM report.sp_writelogs('f_task', v_profondeur, v_exec_start, v_exec_end, v_status, v_nb_rows, NULL); EXCEPTION WHEN OTHERS THEN v_status := 'error'; v_error_message := SQLERRM; v_exec_end := clock_timestamp(); -- Enregistrer le moment de l'erreur -- Journaliser l'erreur dans les logs PERFORM report.sp_writelogs('f_task', v_profondeur, v_exec_start, v_exec_end, v_status, 0, v_error_message); END; $function$ ; /* Fonction de mise à jour des dossiers */ -- DROP FUNCTION report.refresh_dossier(int4); CREATE OR REPLACE FUNCTION report.refresh_dossier(v_profondeur integer) RETURNS void LANGUAGE plpgsql AS $function$ DECLARE v_exec_start TIMESTAMP; v_exec_end TIMESTAMP; v_nb_rows INT; v_status VARCHAR(10); v_error_message VARCHAR(255); v_date_threshold DATE; BEGIN -- Heure de début d'exécution v_exec_start := clock_timestamp(); v_status := 'success'; -- Valeur par défaut du statut -- Déterminer la date de seuil selon le jour de la semaine v_date_threshold := CURRENT_DATE - (v_profondeur * INTERVAL '1 day'); -- Insérer les nouvelles données INSERT INTO report.f_dossier_v2 (dos_id, dos_numero, type_dossier, statut_dossier, dos_date_creation, dos_date_creation_heure, dos_date_cloture, dos_date_cloture_heure, motif_dossier_1, motif_dossier_2, motif_dossier_3, univers, enseigne, domaine, nb_contact, nb_qualif, dmt) select dos.dos_id as dos_id, dos_numero as dos_numero, dos.dtd_libelle as type_dossier, case when dst_libelle is null then '' else dst_libelle end as statut_dossier, date(dos_date_creation) as dos_date_creation, dos_date_creation as dos_date_creation_heure, date(dos_date_cloture) as dos_date_cloture, dos_date_cloture as dos_date_cloture_heure, mtfd_libelle1 as motif_dossier_1, mtfd_libelle2 as motif_dossier_2, mtfd_libelle3 as motif_dossier_3, dossier_univers(dos.dos_id) as univers, dossier_enseigne(dos.dos_id) as enseigne, dossier_domaine(dos.dos_id) as domaine, count(distinct ctc2.ctc_id) as nb_contact, count(distinct ctc2.ctc_id||'_'||ctc2.cqu_rang) as nb_qualif, sum(ctc2.cqu_duree) as dmt FROM public.s_dos_dossier dos left join public.s_dos_contact dctc on dos.dos_id =dctc.dos_id left join public.s_contact_simple ctc2 on dctc.ctc_id=ctc2.ctc_id and dctc.cqu_rang=ctc2.cqu_rang and ctc2.tfl_id not in (5,8) and ctc2.act_id is not null left join public.s_dos_motif mtfd on dos.mtfd_id=mtfd.mtfd_id where dos.dtd_code not like '%MSR%' and (dos_date_creation > v_date_threshold::timestamp or cqu_dt_fin > v_date_threshold::timestamp or dos_date_derniere_maj > v_date_threshold::timestamp) group by dos.dos_id, dos_numero, type_dossier, statut_dossier, dos_date_creation, dos_date_creation_heure, dos_date_cloture, dos_date_cloture_heure, motif_dossier_1, motif_dossier_2, motif_dossier_3 ON CONFLICT (dos_id) DO UPDATE SET dos_id = EXCLUDED.dos_id, dos_numero = EXCLUDED.dos_numero, type_dossier = EXCLUDED.type_dossier, statut_dossier = EXCLUDED.statut_dossier, dos_date_creation = EXCLUDED.dos_date_creation, dos_date_creation_heure = EXCLUDED.dos_date_creation_heure, dos_date_cloture = EXCLUDED.dos_date_cloture, dos_date_cloture_heure = EXCLUDED.dos_date_cloture_heure, motif_dossier_1 = EXCLUDED.motif_dossier_1, motif_dossier_2 = EXCLUDED.motif_dossier_2, motif_dossier_3 = EXCLUDED.motif_dossier_3, domaine = EXCLUDED.domaine, enseigne = EXCLUDED.enseigne, univers = EXCLUDED.univers; -- Nombre de lignes insérées GET DIAGNOSTICS v_nb_rows = ROW_COUNT; -- Prendre l'heure de fin de rafraîchissement v_exec_end := clock_timestamp(); -- Journaliser les informations d'exécution dans les logs PERFORM report.sp_writelogs('f_dossier', v_profondeur, v_exec_start, v_exec_end, v_status, v_nb_rows, NULL); EXCEPTION WHEN OTHERS THEN v_status := 'error'; v_error_message := SQLERRM; v_exec_end := clock_timestamp(); -- Enregistrer le moment de l'erreur -- Journaliser l'erreur dans les logs PERFORM report.sp_writelogs('f_dossier', v_profondeur, v_exec_start, v_exec_end, v_status, 0, v_error_message); END; $function$ ; /* Création des fonctions pour definir domaine, univers, enseigne et ceic pour le 3 types de rapport: - dossier - tache - contact Ci-dessous des exemples de requetes (MONOPRIX) Car la récupération des éléments dépend des exigences clients et, des directives sont données par le conseil. + une table de mapping domaine/univers - a remplir selon le besoin par l'AMOA pour avior le libelle univers */ CREATE TABLE public.r_mapping_domaine_univers ( mtfd_id int4 NULL, valeur_univers varchar NULL ); CREATE OR REPLACE FUNCTION public.contact_domaine(ctcid integer, cqurang integer) RETURNS character varying LANGUAGE sql AS $function$ SELECT case when mtfd_libelle1 is null then 'Sans Domaine' else mtfd_libelle1 end as domaine from s_contact_simple cs LEFT JOIN s_dos_contact dc ON dc.ctc_id = cs.ctc_id AND dc.cqu_rang = cs.cqu_rang left join s_dos_dossier dd on dd.dos_id = dc.dos_id left join s_dos_motif dosmot on dosmot.mtfd_id = dd.mtfd_id where cs.ctc_id=ctcId and cs.cqu_rang=cquRang $function$ ; CREATE OR REPLACE FUNCTION public.contact_enseigne(ctcid integer, cqurang integer) RETURNS character varying LANGUAGE sql AS $function$ SELECT avt_code as enseigne from s_contact_simple cs left join s_type_de_traitement ttr on ttr.ttr_code = cs.ttr_code where ctc_id=ctcId and cqu_rang=cquRang $function$ ; CREATE OR REPLACE FUNCTION public.contact_univers(ctcid integer, cqurang integer) RETURNS character varying LANGUAGE sql AS $function$ SELECT case when mdu.valeur_univers is null then 'Sans Univers' else mdu.valeur_univers end as univers from s_contact_simple cs LEFT JOIN s_dos_contact dc ON dc.ctc_id = cs.ctc_id AND dc.cqu_rang = cs.cqu_rang left join s_dos_dossier dd on dd.dos_id = dc.dos_id left join s_dos_motif dosmot on dosmot.mtfd_id = dd.mtfd_id left join r_mapping_domaine_univers mdu on mdu.mtfd_id=dosmot.mtfd_id1 where cs.ctc_id=ctcId and cs.cqu_rang=cquRang $function$ ; CREATE OR REPLACE FUNCTION public.dossier_domaine(dosid integer) RETURNS character varying LANGUAGE sql AS $function$ SELECT case when mtfd_libelle1 is null then 'Sans Domaine' else mtfd_libelle1 end as domaine from s_dos_dossier dd left join s_dos_motif dosmot on dosmot.mtfd_id = dd.mtfd_id where dd.dos_id=dosId $function$ ; CREATE OR REPLACE FUNCTION public.dossier_enseigne(dosid integer) RETURNS character varying LANGUAGE sql AS $function$ select case when dtd_libelle ilike '%MarketPlace%' then 'Marketplace Out' when dtd_libelle ilike '%NATURALIA%' then 'NATURALIA' when dtd_libelle ilike '%MSR%' then 'MSR' else 'MONOPRIX' end from s_dos_dossier dos where dos.dos_id=dosId $function$ ; CREATE OR REPLACE FUNCTION public.dossier_univers(dosid integer) RETURNS character varying LANGUAGE sql AS $function$ SELECT case when mdu.valeur_univers is null then 'Sans Univers' else mdu.valeur_univers end as univers from s_dos_dossier dd left join s_dos_motif dosmot on dosmot.mtfd_id = dd.mtfd_id left join r_mapping_domaine_univers mdu on mdu.mtfd_id=dosmot.mtfd_id1 where dd.dos_id=dosId $function$ ; CREATE OR REPLACE FUNCTION public.tache_domaine(taeid integer) RETURNS character varying LANGUAGE sql AS $function$ select mtfd_libelle1 as domaine from s_tache tac inner join s_tache_definition def on def.dta_id = tac.dta_id left join s_contact_simple cs on cs.ctc_id = tac.ctc_id_traite_par and cs.cqu_rang = tac.cqu_rang_traite_par left join s_dos_dossier dd on dd.dos_id = tac.dos_id left join s_dos_motif dosmot on dosmot.mtfd_id = dd.mtfd_id where tae_id = taeId $function$ ; CREATE OR REPLACE FUNCTION public.tache_enseigne(taeid integer) RETURNS character varying LANGUAGE sql AS $function$ select coalesce(ttr.avt_code, ttr1.avt_code) as enseigne from s_tache tac inner join s_tache_definition def on def.dta_id = tac.dta_id left join s_type_de_traitement ttr1 on ttr1.ttr_code = def.ttr_code left join s_contact_simple cs on cs.ctc_id = tac.ctc_id_traite_par and cs.cqu_rang = tac.cqu_rang_traite_par left join s_type_de_traitement ttr on ttr.ttr_code = cs.ttr_code where tae_id = taeId $function$ ; CREATE OR REPLACE FUNCTION public.tache_univers(taeid integer) RETURNS character varying LANGUAGE sql AS $function$ select mdu.valeur_univers as univers from s_tache tac inner join s_tache_definition def on def.dta_id = tac.dta_id left join s_contact_simple cs on cs.ctc_id = tac.ctc_id_traite_par and cs.cqu_rang = tac.cqu_rang_traite_par left join s_dos_dossier dd on dd.dos_id = tac.dos_id left join s_dos_motif dosmot on dosmot.mtfd_id = dd.mtfd_id left join r_mapping_domaine_univers mdu on mdu.mtfd_id=dosmot.mtfd_id1 where tae_id = taeId $function$ ;