From 71eccaf7d0d831421f1fdf60f01e75e1b8edda1e Mon Sep 17 00:00:00 2001 From: "florian.joriot@unicaen.fr" <florian.joriot@unicaen.fr> Date: Tue, 14 Mar 2023 16:03:53 +0100 Subject: [PATCH] =?UTF-8?q?Maj=20de=20V=5FCONTRAT=5FSERVICES.sql=20pour=20?= =?UTF-8?q?remonter=20referentiel=20+=20mission=20+=20enseignement=20contr?= =?UTF-8?q?actualis=C3=A9=20ou=20non=20(pr=C3=A9visionnel=20uniquement)?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- data/data_updater_config.php | 4 + data/ddl/table/VOLUME_HORAIRE_REF.php | 12 ++ data/ddl/view/V_CONTRAT_MAIN.sql | 32 ++++- data/ddl/view/V_CONTRAT_SERVICES.sql | 183 +++++++++++++++++--------- data/ddl_columns_pos.php | 6 + data/nomenclatures.php | 35 ++--- 6 files changed, 181 insertions(+), 91 deletions(-) diff --git a/data/data_updater_config.php b/data/data_updater_config.php index c446d4c579..eaf2b55785 100644 --- a/data/data_updater_config.php +++ b/data/data_updater_config.php @@ -252,6 +252,10 @@ return [ 'TYPE_PIECE_JOINTE_ID' => ['transformer' => 'SELECT id FROM type_piece_jointe WHERE histo_destruction IS NULL AND code = %s'], ],], ], + 'TYPE_SERVICE' => [ + 'actions' => ['install', 'update'], + 'key' => 'CODE', + ], 'WF_ETAPE_DEP' => [ 'actions' => ['install'], 'key' => ['ETAPE_SUIV_ID', 'ETAPE_PREC_ID'], diff --git a/data/ddl/table/VOLUME_HORAIRE_REF.php b/data/ddl/table/VOLUME_HORAIRE_REF.php index a8cc7ed49c..989523a97e 100644 --- a/data/ddl/table/VOLUME_HORAIRE_REF.php +++ b/data/ddl/table/VOLUME_HORAIRE_REF.php @@ -21,6 +21,18 @@ return [ 'position' => 13, 'commentaire' => NULL, ], + 'CONTRAT_ID' => [ + 'name' => 'CONTRAT_ID', + 'type' => 'int', + 'bdd-type' => 'NUMBER', + 'length' => 0, + 'scale' => NULL, + 'precision' => NULL, + 'nullable' => TRUE, + 'default' => NULL, + 'position' => 16, + 'commentaire' => NULL, + ], 'HEURES' => [ 'name' => 'HEURES', 'type' => 'float', diff --git a/data/ddl/view/V_CONTRAT_MAIN.sql b/data/ddl/view/V_CONTRAT_MAIN.sql index 6d7e0ed6fd..4d5cfc41bf 100644 --- a/data/ddl/view/V_CONTRAT_MAIN.sql +++ b/data/ddl/view/V_CONTRAT_MAIN.sql @@ -1,7 +1,26 @@ CREATE OR REPLACE FORCE VIEW V_CONTRAT_MAIN AS WITH hs AS ( - SELECT contrat_id, SUM(heures) "serviceTotal", MAX("libelleAutres") "libelleAutres" FROM V_CONTRAT_SERVICES GROUP BY contrat_id -) + SELECT contrat_id, SUM(heures) "serviceTotal" FROM V_CONTRAT_SERVICES GROUP BY contrat_id +), +la AS( + SELECT + contrat_id, + LISTAGG( libelle, ',') WITHIN GROUP (ORDER BY libelle) autre_libelles + FROM + ( + SELECT DISTINCT + c.contrat_id, + ti.libelle libelle + FROM + contrat c + JOIN volume_horaire vh ON c.id = vh.contrat_id + JOIN type_intervention ti ON ti.id = vh.type_intervention_id + LEFT JOIN hs ON hs.contrat_id = c.id + WHERE + ti.code NOT IN ('CM','TD','TP') + ) + GROUP BY contrat_id + ) SELECT ct.annee_id, ct.structure_id, ct.intervenant_id, @@ -52,7 +71,7 @@ SELECT ct.annee_id, WHEN ct.est_projet = 1 AND ct.est_contrat = 0 THEN 'Projet d''avenant' WHEN ct.est_projet = 0 AND ct.est_contrat = 0 THEN 'Avenant n°' || ct.contrat_id || '.' || ct.numero_avenant END "titreCourt" -FROM (SELECT c.*, + FROM (SELECT c.*, i.annee_id annee_id, fr.id formule_resultat_id, s.libelle_court "composante", @@ -96,10 +115,10 @@ FROM (SELECT c.*, ELSE '' END "exemplaire2", REPLACE(ltrim(to_char(COALESCE(hs."serviceTotal", 0), '999999.00')), '.', ',') "serviceTotal", CASE - WHEN hs."libelleAutres" IS NOT NULL - THEN '*Dont type(s) intervention(s) : ' || hs."libelleAutres" END "legendeAutresHeures", + WHEN la.autre_libelles IS NOT NULL + THEN '*Dont type(s) intervention(s) : ' || la.autre_libelles END "legendeAutresHeures", CASE - WHEN hs."libelleAutres" IS NOT NULL THEN 'Autres heures*' + WHEN la.autre_libelles IS NOT NULL THEN 'Autres heures*' ELSE 'Autres heures' END "enteteAutresHeures", CASE WHEN c.contrat_id IS NULL THEN 1 ELSE 0 END est_contrat, CASE WHEN v.id IS NULL THEN 1 ELSE 0 END est_projet, @@ -120,6 +139,7 @@ FROM (SELECT c.*, LEFT JOIN formule_resultat fr ON fr.intervenant_id = i.id AND fr.type_volume_horaire_id = tvh.id AND fr.etat_volume_horaire_id = evh.id LEFT JOIN taux_remu tr ON tr.code = OSE_PAIEMENT.get_code_taux_remu_legal() LEFT JOIN hs ON hs.contrat_id = c.id + LEFT JOIN la ON la.contrat_id = c.id LEFT JOIN contrat cp ON cp.id = c.contrat_id WHERE c.histo_destruction IS NULL diff --git a/data/ddl/view/V_CONTRAT_SERVICES.sql b/data/ddl/view/V_CONTRAT_SERVICES.sql index fccc385811..28183a046d 100644 --- a/data/ddl/view/V_CONTRAT_SERVICES.sql +++ b/data/ddl/view/V_CONTRAT_SERVICES.sql @@ -1,62 +1,127 @@ CREATE OR REPLACE FORCE VIEW V_CONTRAT_SERVICES AS WITH services AS ( - SELECT - c.id contrat_id, - str.libelle_court "serviceComposante", - ep.code "serviceCode", - ep.libelle "serviceLibelle", - CASE WHEN ti.code = 'CM' THEN vh.heures ELSE 0 END heures_cm, - CASE WHEN ti.code = 'TD' THEN vh.heures ELSE 0 END heures_td, - CASE WHEN ti.code = 'TP' THEN vh.heures ELSE 0 END heures_tp, - CASE WHEN ti.code NOT IN ('CM','TD','TP') THEN vh.heures ELSE 0 END heures_autres, - CASE WHEN ti.code NOT IN ('CM','TD','TP') THEN ti.libelle ELSE '' END type_intervention_libelle, - vh.heures heures_totales - FROM - contrat c - JOIN STRUCTURE str ON str.id = c.structure_id - JOIN volume_horaire vh ON vh.contrat_id = c.id AND vh.histo_destruction IS NULL - JOIN service s ON s.id = vh.service_id - JOIN type_intervention ti ON ti.id = vh.type_intervention_id - LEFT JOIN element_pedagogique ep ON ep.id = s.element_pedagogique_id - - -) , -servicesAutres AS ( - SELECT - t.contrat_id contrat_id, - listagg(t.type_intervention_libelle, ', ') WITHIN GROUP (ORDER BY t.type_intervention_libelle) type_intervention_libelle - FROM ( - SELECT DISTINCT - c.id contrat_id, - ti.libelle || ' (' || SUM(vh.heures) || ' h)' type_intervention_libelle - FROM - contrat c - JOIN volume_horaire vh ON vh.contrat_id = c.id AND vh.histo_destruction IS NULL - JOIN type_intervention ti ON ti.id = vh.type_intervention_id - WHERE ti.code NOT IN ('CM','TD','TP') - GROUP BY - c.id, ti.libelle - ) t + SELECT + s.intervenant_id intervenant_id, + ts.code code, + c.id contrat_id, + str.libelle_court "serviceComposante", + ep.code "serviceCode", + ep.libelle "serviceLibelle", + SUM(CASE WHEN ti.code = 'CM' THEN vh.heures ELSE 0 END) heures_cm, + SUM(CASE WHEN ti.code = 'TD' THEN vh.heures ELSE 0 END) heures_td, + SUM(CASE WHEN ti.code = 'TP' THEN vh.heures ELSE 0 END) heures_tp, + SUM(CASE WHEN ti.code NOT IN ('CM','TD','TP') THEN vh.heures ELSE 0 END) heures_autres, + SUM(vh.heures) heures_totales + FROM + volume_horaire vh + JOIN service s ON s.id = vh.service_id + JOIN type_intervention ti ON ti.id = vh.type_intervention_id + JOIN element_pedagogique ep ON ep.id = s.element_pedagogique_id + JOIN type_volume_horaire tvh ON tvh.id = vh.type_volume_horaire_id + LEFT JOIN validation_vol_horaire vvh ON vvh.volume_horaire_id = vh.id + JOIN validation v ON v.id = vvh.validation_id AND v.histo_destruction IS NULL + LEFT JOIN contrat c ON c.id = vh.contrat_id + LEFT JOIN structure str ON c.structure_id = str.id + JOIN type_service ts ON ts.code = 'ENS' + WHERE + vh.histo_destruction IS NULL + AND tvh.code = 'PREVU' + AND (v.id IS NOT NULL OR vh.auto_validation = 1) GROUP BY - t.contrat_id - ) -SELECT - - s.contrat_id, - s."serviceComposante", - s."serviceCode", - s."serviceLibelle", - CASE WHEN SUM(s.heures_cm) = 0 THEN to_char(0) ELSE REPLACE(ltrim(to_char(SUM(s.heures_cm), '999999.00')),'.',',') END "cm", - CASE WHEN SUM(s.heures_td) = 0 THEN to_char(0) ELSE REPLACE(ltrim(to_char(SUM(s.heures_td), '999999.00')),'.',',') END "td", - CASE WHEN SUM(s.heures_tp) = 0 THEN to_char(0) ELSE REPLACE(ltrim(to_char(SUM(s.heures_tp), '999999.00')),'.',',') END "tp", - CASE WHEN SUM(s.heures_autres) = 0 THEN to_char(0) ELSE REPLACE(ltrim(to_char(SUM(s.heures_autres), '999999.00')),'.',',') END "autres", - SUM(heures_totales) heures, - SUM(heures_totales) "serviceHeures", - MAX(sa.type_intervention_libelle) "libelleAutres" - FROM services s - LEFT JOIN servicesAutres sa ON sa.contrat_id = s.contrat_id - GROUP BY - s.contrat_id, - s."serviceComposante", - s."serviceCode", - s."serviceLibelle" \ No newline at end of file + s.intervenant_id, + c.id, + str.libelle_court, + ep.code, + ep.libelle, + ts.code + UNION ALL + SELECT + sr.intervenant_id intervenant_id, + ts.code code, + c.id contrat_id, + str.libelle_court "serviceComposante", + fr.code "serviceCode", + fr.libelle_long "serviceLibelle", + 0 heures_cm, + 0 heures_td, + 0 heures_tp, + SUM(vhr.heures) heures_autres, + SUM(vhr.heures) heures_totales + FROM + volume_horaire_ref vhr + JOIN service_referentiel sr ON sr.id = vhr.service_referentiel_id + JOIN fonction_referentiel fr ON fr.id = sr.fonction_id + JOIN type_volume_horaire tvh ON tvh.id = vhr.type_volume_horaire_id + LEFT JOIN validation_vol_horaire_ref vvhr ON vvhr.volume_horaire_ref_id = vhr.id + JOIN validation v ON v.id = vvhr.validation_id AND v.histo_destruction IS NULL + LEFT JOIN contrat c ON c.id = vhr.contrat_id + LEFT JOIN structure str ON c.structure_id = str.id + JOIN type_service ts ON ts.code = 'REF' + WHERE + vhr.histo_destruction IS NULL + AND tvh.code = 'PREVU' + AND (v.id IS NOT NULL OR vhr.auto_validation = 1) + GROUP BY + sr.intervenant_id, + c.id, + str.libelle_court, + ts.code, + fr.code, + fr.libelle_long + UNION ALL + SELECT + m.intervenant_id intervenant_id, + ts.code code, + c.id contrat_id, + str.libelle_court "serviceComposante", + tm.code "serviceCode", + tm.libelle "serviceLibelle", + 0 heures_cm, + 0 heures_td, + 0 heures_tp, + SUM(vhm.heures) heures_autres, + SUM(vhm.heures) heures_totales + FROM + volume_horaire_mission vhm + JOIN mission m ON m.id = vhm.mission_id + JOIN type_mission tm ON m.type_mission_id = tm.id + LEFT JOIN contrat c ON c.id = vhm.contrat_id + LEFT JOIN structure str ON c.structure_id = str.id + LEFT JOIN validation_vol_horaire_miss vvhm ON vvhm.volume_horaire_mission_id = vhm.id + JOIN validation v ON v.id = vvhm.validation_id AND v.histo_destruction IS NULL + JOIN type_volume_horaire tvh ON tvh.id = vhm.type_volume_horaire_id + JOIN type_service ts ON ts.code = 'MIS' + WHERE + vhm.histo_destruction IS NULL + AND tvh.code = 'PREVU' + AND (v.id IS NOT NULL OR vhm.auto_validation = 1) + GROUP BY + m.intervenant_id, + c.id, + str.libelle_court, + ts.code, + tm.code, + tm.libelle + ) + SELECT + s.intervenant_id, + s.contrat_id, + s."serviceComposante", + s."serviceCode", + s."serviceLibelle", + CASE WHEN SUM(s.heures_cm) = 0 THEN to_char(0) ELSE REPLACE(ltrim(to_char(SUM(s.heures_cm), '999999.00')),'.',',') END "cm", + CASE WHEN SUM(s.heures_td) = 0 THEN to_char(0) ELSE REPLACE(ltrim(to_char(SUM(s.heures_td), '999999.00')),'.',',') END "td", + CASE WHEN SUM(s.heures_tp) = 0 THEN to_char(0) ELSE REPLACE(ltrim(to_char(SUM(s.heures_tp), '999999.00')),'.',',') END "tp", + CASE WHEN SUM(s.heures_autres) = 0 THEN to_char(0) ELSE REPLACE(ltrim(to_char(SUM(s.heures_autres), '999999.00')),'.',',') END "autres", + SUM(heures_totales) heures, + SUM(heures_totales) "serviceHeures", + s.code "typeService" + FROM + services s + GROUP BY + s.intervenant_id, + s.contrat_id, + s."serviceComposante", + s."serviceCode", + s."serviceLibelle", + s.code \ No newline at end of file diff --git a/data/ddl_columns_pos.php b/data/ddl_columns_pos.php index ef1328782a..ac33ebb890 100644 --- a/data/ddl_columns_pos.php +++ b/data/ddl_columns_pos.php @@ -1933,6 +1933,7 @@ return [ 'AUTO_VALIDATION', 'HORAIRE_DEBUT', 'HORAIRE_FIN', + 'CONTRAT_ID', ], 'WF_DEP_BLOQUANTE' => [ 'ID', @@ -2275,6 +2276,11 @@ return [ 'STATUT_CODE', 'STATUT_DOSSIER_CODE', ], + 'TYPE_SERVICE' => [ + 'ID', + 'CODE', + 'LIBELLE', + ], ]; //@formatter:on diff --git a/data/nomenclatures.php b/data/nomenclatures.php index 6208b61af0..00413b0ac3 100644 --- a/data/nomenclatures.php +++ b/data/nomenclatures.php @@ -899,38 +899,21 @@ return [ ], ], - 'TAUX_REMU' => [ + 'TYPE_SERVICE' => [ [ 'ID' => 1, - 'CODE' => 'TLD', - 'LIBELLE' => 'Taux légal par défaut', - ], - ], - - 'TAUX_REMU_VALEUR' => [ - [ - 'ID' => 1, - 'TAUX_REMu_ID' => 1, - 'DATE_EFFET' => '27/07/2009', - 'VALEUR' => 40.58, + 'CODE' => 'ENS', + 'LIBELLE' => 'Enseignement', ], [ - 'ID' => 2, - 'TAUX_REMu_ID' => 1, - 'DATE_EFFET' => '25/06/2014', - 'VALEUR' => 40.91, - ], - [ - 'ID' => 3, - 'TAUX_REMu_ID' => 1, - 'DATE_EFFET' => '01/02/2017', - 'VALEUR' => 41.41, + 'ID' => 2, + 'CODE' => 'REF', + 'LIBELLE' => 'Référentiel', ], [ - 'ID' => 4, - 'TAUX_REMu_ID' => 1, - 'DATE_EFFET' => '01/07/2022', - 'VALEUR' => 42.86, + 'ID' => 3, + 'CODE' => 'MIS', + 'LIBELLE' => 'Mission', ], ], -- GitLab