diff --git a/data/ddl/sequence.php b/data/ddl/sequence.php
index 3b35cd1cfd2778712de8e4504618f2944d48f675..e69f80821cc7975cad50f7723ab7a2b447e8d587 100644
--- a/data/ddl/sequence.php
+++ b/data/ddl/sequence.php
@@ -39,9 +39,15 @@ return [
     'FICHIER_ID_SEQ',
     'FONCTION_REFERENTIEL_ID_SEQ',
     'FORMULE_ID_SEQ',
+    'FORMULE_RESULTAT_ID_SEQ',
     'FORMULE_RESULTAT_INTERVENANT_ID_SEQ',
+    'FORMULE_RESULTAT_SERREF_ID_SEQ',
+    'FORMULE_RESULTAT_SERVIC_ID_SEQ',
+    'FORMULE_RESULTAT_VH_ID_SEQ',
+    'FORMULE_RESULTAT_VH_REF_ID_SEQ',
     'FORMULE_RESULTAT_VOLUME_HORAIRE_ID_SEQ',
     'FTEST_INTERVENANT_ID_SEQ',
+    'FTEST_STRUCTURE_ID_SEQ',
     'FTEST_VOLUME_HORAIRE_ID_SEQ',
     'GRADE_ID_SEQ',
     'GROUPE_ID_SEQ',
@@ -161,15 +167,15 @@ return [
     'UNICAEN_SIGNATURE_PROCESS_STEP_ID_SEQ',
     'UNICAEN_SIGNATURE_RECIPIENT_ID_SEQ',
     'UNICAEN_SIGNATURE_SIGNATUREFLO',
-    'UNICAEN_SIGNATURE_SIGNATUREFLOWSTEP_ID_SEQ',
     'UNICAEN_SIGNATURE_SIGNATUREFLOW_ID_SEQ',
+    'UNICAEN_SIGNATURE_SIGNATUREFLOWSTEP_ID_SEQ',
     'UNICAEN_SIGNATURE_SIGNATURE_ID',
     'UNICAEN_SIGNATURE_SIGNATURE_ID_SEQ',
     'UNICAEN_SIGNATURE_SIGNATUR_ID',
     'UTILISATEUR_ID_SEQ',
     'VALIDATION_ID_SEQ',
-    'VALIDATION_VOL_HORAIRE_ID_SEQ',
     'VALIDATION_VOL_HORAIRE__ID_SEQ',
+    'VALIDATION_VOL_HORAIRE_ID_SEQ',
     'VOIRIE_ID_SEQ',
     'VOLUME_HORAIRE_CHARGE_ID_SEQ',
     'VOLUME_HORAIRE_ENS_ID_SEQ',
diff --git a/data/ddl/view/V_CONTRAT_MAIN.sql b/data/ddl/view/V_CONTRAT_MAIN.sql
index fc37c51638caae3b581e74c3fa4cec693fe3e620..1f5497d86fc01534a95c22cc382ed48c867e04f1 100644
--- a/data/ddl/view/V_CONTRAT_MAIN.sql
+++ b/data/ddl/view/V_CONTRAT_MAIN.sql
@@ -1,6 +1,6 @@
 CREATE OR REPLACE FORCE VIEW V_CONTRAT_MAIN AS
 WITH hs AS (
-  SELECT contrat_id, SUM(heures) "serviceTotal", SUM("hetd") "hetdContrat" FROM V_CONTRAT_SERVICES GROUP BY contrat_id
+  SELECT contrat_id, SUM(heures) "serviceTotal", SUM(hetd) "hetdContrat" FROM tbl_contrat GROUP BY contrat_id
 ),
 la AS(
    SELECT
@@ -39,7 +39,7 @@ lm AS(
     )
     GROUP BY contrat_id
 )
-SELECT ct.annee_id,
+SELECT DISTINCT ct.annee_id,
        ct.structure_id,
        ct.intervenant_id,
        ct.formule_resultat_id,
diff --git a/data/ddl/view/V_CONTRAT_SERVICES.sql b/data/ddl/view/V_CONTRAT_SERVICES.sql
index f17e88f10302ba78f2a607a9b298e33f7f8eb0ca..fb26cfedcc9cfabf353a8fd1bf40d97b42666a94 100644
--- a/data/ddl/view/V_CONTRAT_SERVICES.sql
+++ b/data/ddl/view/V_CONTRAT_SERVICES.sql
@@ -1,212 +1,92 @@
 CREATE OR REPLACE FORCE VIEW V_CONTRAT_SERVICES AS
-WITH services AS (
+SELECT
+  t.intervenant_id,
+  t.contrat_id,
+  t.type_service_id,
+  t.structure_id,
+  t.element_pedagogique_id,
+  t.fonction_referentiel_id,
+  t.mission_id,
+  t.type_mission_id,
 
-        SELECT
-            s.intervenant_id                                                            intervenant_id,
-            c.id                                                                        contrat_id,
-            str.id                                                                      structure_id,
-            str.libelle_court                                                           "serviceComposante",
-            ep.code                                                                     "serviceCode",
-            ep.libelle                                                                  "serviceLibelle",
-            ep.id                                                                       element_pedagogique_id,
-            NULL                                                                        fonction_referentiel_id,
-            NULL                                                                        type_mission_id,
-            NULL                                                                        mission_id,
-            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,
-            SUM(frvh.total)                                                             hetd,
-            'ENS'                                                                       "typeServiceCode",
-            p.libelle_long                                                              "periode"
-        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
-            JOIN etat_volume_horaire evh ON evh.code = 'valide'
-            JOIN formule_resultat_intervenant fr ON fr.intervenant_id = s.intervenant_id AND fr.etat_volume_horaire_id = evh.id
-            JOIN formule_resultat_volume_horaire frvh ON frvh.volume_horaire_id = vh.id AND frvh.formule_resultat_intervenant_id = fr.id
-            JOIN STRUCTURE str ON ep.structure_id = str.id
-            LEFT JOIN contrat c ON c.id = vh.contrat_id
-            LEFT JOIN periode p on vh.periode_id = p.id
-        WHERE
-            vh.histo_destruction IS NULL
-            AND tvh.code = 'PREVU'
-        GROUP BY
-            s.intervenant_id,
-            c.id,
-            str.libelle_court,
-            ep.code,
-            ep.libelle,
-            str.id,
-            ep.id,
-            p.libelle_long
+  t.type_service           "typeService",
+  t.service_composante     "serviceComposante",
+  t.periode                "periode",
+  t.service_code,
+  t.service_code           "serviceCode",
+  t.service_libelle,
+  t.service_libelle        "serviceLibelle",
 
+  t.service_heures,
+  t.service_heures         "serviceHeures",
 
-    UNION ALL
+  SUM(t.heures)            heures,
+  SUM(t.hetd)              "hetd",
 
+  CASE WHEN SUM(t.cm) = 0 THEN '0' ELSE REPLACE(ltrim(to_char(SUM(t.cm), '999999.00')),'.',',') END "cm",
+  CASE WHEN SUM(t.td) = 0 THEN '0' ELSE REPLACE(ltrim(to_char(SUM(t.td), '999999.00')),'.',',') END "td",
+  CASE WHEN SUM(t.tp) = 0 THEN '0' ELSE REPLACE(ltrim(to_char(SUM(t.tp), '999999.00')),'.',',') END "tp",
+  CASE WHEN SUM(t.autres) = 0 THEN '0' ELSE REPLACE(ltrim(to_char(SUM(t.autres), '999999.00')),'.',',') END "autres"
+FROM
+  (
+  SELECT
+    tblc.intervenant_id                                  intervenant_id,
+    tblc.contrat_id                                      contrat_id,
+    tblc.type_service_id                                 type_service_id,
+    str.id                                               structure_id,
+    ep.id                                                element_pedagogique_id,
+    fr.id                                                fonction_referentiel_id,
+    m.id                                                 mission_id,
+    tm.id                                                type_mission_id,
 
-        SELECT
-            sr.intervenant_id       intervenant_id,
-            c.id                    contrat_id,
-            str.id                  structure_id,
-            str.libelle_court       "serviceComposante",
-            fr.code                 "serviceCode",
-            fr.libelle_long         "serviceLibelle",
-            NULL                    element_pedagogique_id,
-            fr.id                   fonction_referentiel_id,
-            NULL                    type_mission_id,
-            NULL                    mission_id,
-            0                       heures_cm,
-            0                       heures_td,
-            0                       heures_tp,
-            SUM(vhr.heures)         heures_autres,
-            SUM(vhr.heures)         heures_totales,
-            SUM(frvh.total)         hetd,
-            'REF'                  "typeServiceCode",
-            NULL                   "periode"
-            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
-            JOIN etat_volume_horaire evh ON evh.code = 'valide'
-            JOIN formule_resultat_intervenant fri ON fri.intervenant_id = sr.intervenant_id AND fri.etat_volume_horaire_id = evh.id
-            LEFT JOIN formule_resultat_volume_horaire frvh ON frvh.volume_horaire_ref_id = vhr.id AND frvh.formule_resultat_intervenant_id = fri.id
-            LEFT JOIN contrat c ON c.id = vhr.contrat_id
-            LEFT JOIN STRUCTURE str ON sr.structure_id = str.id
-        WHERE
-            vhr.histo_destruction IS NULL
-            AND tvh.code = 'PREVU'
-        GROUP BY
-            sr.intervenant_id,
-            c.id,
-            str.libelle_court,
-            fr.code,
-            fr.libelle_long,
-            str.id,
-            fr.id
+    ts.code                                           type_service,
+    str.libelle_court                                    service_composante,
+    p.libelle_long                                       periode,
+    COALESCE(tm.code, fr.code, ep.code)                  service_code,
+    COALESCE(tm.libelle, fr.libelle_long, ep.libelle)    service_libelle,
 
-    UNION ALL
+    -- somme par contrat
+    SUM(tblc.heures) OVER (PARTITION BY tblc.intervenant_id, tblc.contrat_id, tblc.type_service_id, COALESCE(ep.id,tm.id,fr.id) ,p.libelle_long) service_heures,
 
+    -- heures atomiques
+    tblc.heures            heures,
+    tblc.hetd              hetd,
+    tblc.cm                cm,
+    tblc.td                td,
+    tblc.tp                tp,
+    tblc.autres            autres
 
-        SELECT
-            m.intervenant_id        intervenant_id,
-            c.id                    contrat_id,
-            str.id                  structure_id,
-            str.libelle_court       "serviceComposante",
-            tm.code                 "serviceCode",
-            tm.libelle              "serviceLibelle",
-            NULL                    element_pedagogique_id,
-            NULL                    fonction_referentiel_id,
-            tm.id                   type_mission_id,
-            m.id                    mission_id,
-            0                       heures_cm,
-            0                       heures_td,
-            0                       heures_tp,
-            SUM(vhm.heures)         heures_autres,
-            SUM(vhm.heures)         heures_totales,
-            SUM(vhm.heures)         hetd,
-            'MIS'                   "typeServiceCode",
-            NULL                    "periode"
- 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
-            JOIN STRUCTURE str ON m.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 validation_mission vm ON vm.mission_id = m.id
-            JOIN validation v2 ON v2.id = vm.validation_id AND v2.histo_destruction IS NULL
-        WHERE
-            vhm.histo_destruction IS NULL
-            AND tvh.code = 'PREVU'
-            AND (v.id IS NOT NULL OR vhm.auto_validation = 1)
-            AND m.histo_destruction IS NULL
-            AND (v2.id IS NOT NULL OR vhm.auto_validation = 1)
-        GROUP BY
-            m.intervenant_id,
-            c.id,
-            str.libelle_court,
-            tm.code,
-            tm.libelle,
-            str.id,
-            tm.id,
-            m.id
-        )
+  FROM
+              tbl_contrat        tblc
+         JOIN type_service         ts ON ts.id = tblc.type_service_id
+    LEFT JOIN service               s ON s.id = tblc.service_id
+    LEFT JOIN element_pedagogique  ep ON ep.id = s.element_pedagogique_id
+    LEFT JOIN volume_horaire       vh ON vh.id = tblc.volume_horaire_id
+    LEFT JOIN periode               p ON p.id = vh.periode_id
 
-        SELECT
-            rownum id,
-            res.intervenant_id,
-            res.contrat_id,
-            res.type_service_id,
-            res.structure_id,
-            res."serviceCode"   service_code,
-            res."serviceLibelle" service_libelle,
-            res.element_pedagogique_id,
-            res.fonction_referentiel_id,
-            res.type_mission_id,
-            res.mission_id,
-            res."cm" cm,
-            res."td" td,
-            res."tp" tp,
-            res."autres" autres,
-            res.heures,
-            res."serviceHeures" service_heures,
-            res."serviceComposante",
-            res."serviceCode",
-            res."serviceLibelle",
-            res."cm",
-            res."td",
-            res."tp",
-            res."autres",
-            res."serviceHeures",
-            res."hetd",
-            res."typeService",
-            res."periode"
-        FROM
-        (
-            SELECT
-                s.intervenant_id                                                                                                                 intervenant_id,
-                s.contrat_id                                                                                                                     contrat_id,
-                ts.id                                                                                                                            type_service_id,
-                s.structure_id                                                                                                                   structure_id,
-                s."serviceComposante"                                                                                                            "serviceComposante",
-                s."serviceCode"                                                                                                                  "serviceCode",
-                s."serviceLibelle"                                                                                                               "serviceLibelle",
-                s.element_pedagogique_id                                                                                                         element_pedagogique_id,
-                s.fonction_referentiel_id                                                                                                        fonction_referentiel_id,
-                s.type_mission_id                                                                                                                type_mission_id,
-                s.mission_id                                                                                                                     mission_id,
-                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",
-                SUM(hetd)                                                                                                                        "hetd",
-                s."typeServiceCode"                                                                                                              "typeService",
-                s."periode"                                                                                                                      "periode"
-            FROM
-                services s
-                JOIN TYPE_SERVICE ts ON ts.code = s."typeServiceCode"
-            GROUP BY
-                s.intervenant_id,
-                s.contrat_id,
-                s."serviceComposante",
-                s."serviceCode",
-                s."serviceLibelle",
-                s."typeServiceCode",
-                s.structure_id,
-                ts.id,
-                element_pedagogique_id,
-                fonction_referentiel_id,
-                type_mission_id,
-                mission_id,
-                s."periode"
-        ) res
\ No newline at end of file
+    LEFT JOIN service_referentiel  sr ON sr.id = tblc.service_referentiel_id
+    LEFT JOIN fonction_referentiel fr ON fr.id = sr.fonction_id
+
+    LEFT JOIN mission               m ON m.id = tblc.mission_id
+    LEFT JOIN type_mission         tm ON tm.id = m.type_mission_id
+
+    LEFT JOIN structure           str ON str.id = COALESCE(m.structure_id, sr.structure_id, ep.structure_id)
+  WHERE
+    tblc.actif = 1
+) t
+GROUP BY
+  t.intervenant_id,
+  t.contrat_id,
+  t.type_service_id,
+  t.structure_id,
+  t.element_pedagogique_id,
+  t.fonction_referentiel_id,
+  t.mission_id,
+  t.type_mission_id,
+
+  t.type_service,
+  t.service_composante,
+  t.periode,
+  t.service_code,
+  t.service_libelle,
+  t.service_heures
\ No newline at end of file
diff --git a/data/ddl_columns_pos.php b/data/ddl_columns_pos.php
index c7d5d5f47e22d38ea542ca43cdaee7f06ebf34fa..1831e16a19cfeae79750186bb6f5f2fc3eba3d40 100644
--- a/data/ddl_columns_pos.php
+++ b/data/ddl_columns_pos.php
@@ -2887,6 +2887,78 @@ return [
         'PJ_ACTIVE',
         'DOSSIER_SITUATION_MATRIMONIALE',
     ],
+    'SAVE_V24_FRES_SERVICE'               => [
+        'ID',
+        'FORMULE_RESULTAT_ID',
+        'SERVICE_ID',
+        'HEURES_COMPL_FI',
+        'HEURES_COMPL_FA',
+        'HEURES_COMPL_FC',
+        'HEURES_COMPL_FC_MAJOREES',
+        'SERVICE_FA',
+        'SERVICE_FC',
+        'SERVICE_FI',
+        'TOTAL',
+    ],
+    'SAVE_V24_FRES_SERVICE_REF'           => [
+        'ID',
+        'FORMULE_RESULTAT_ID',
+        'SERVICE_REFERENTIEL_ID',
+        'HEURES_COMPL_REFERENTIEL',
+        'SERVICE_REFERENTIEL',
+        'TOTAL',
+    ],
+    'SAVE_V24_FRES_VH'                    => [
+        'ID',
+        'FORMULE_RESULTAT_ID',
+        'VOLUME_HORAIRE_ID',
+        'HEURES_COMPL_FI',
+        'HEURES_COMPL_FA',
+        'HEURES_COMPL_FC',
+        'HEURES_COMPL_FC_MAJOREES',
+        'SERVICE_FA',
+        'SERVICE_FC',
+        'SERVICE_FI',
+        'TOTAL',
+    ],
+    'SAVE_V24_FRES_VH_REF'                => [
+        'ID',
+        'FORMULE_RESULTAT_ID',
+        'VOLUME_HORAIRE_REF_ID',
+        'HEURES_COMPL_REFERENTIEL',
+        'SERVICE_REFERENTIEL',
+        'TOTAL',
+    ],
+    'VCS'                                 => [
+        'ID',
+        'INTERVENANT_ID',
+        'CONTRAT_ID',
+        'TYPE_SERVICE_ID',
+        'STRUCTURE_ID',
+        'SERVICE_CODE',
+        'SERVICE_LIBELLE',
+        'ELEMENT_PEDAGOGIQUE_ID',
+        'FONCTION_REFERENTIEL_ID',
+        'TYPE_MISSION_ID',
+        'MISSION_ID',
+        'CM',
+        'TD',
+        'TP',
+        'AUTRES',
+        'HEURES',
+        'SERVICE_HEURES',
+        'serviceComposante',
+        'serviceCode',
+        'serviceLibelle',
+        'cm',
+        'td',
+        'tp',
+        'autres',
+        'serviceHeures',
+        'hetd',
+        'typeService',
+        'periode',
+    ],
 ];
 
 //@formatter:on