Cristian Lucero 5 år sedan
förälder
incheckning
07e6650a84
1 ändrade filer med 575 tillägg och 43 borttagningar
  1. 575 43
      sp_create_replace.sql

+ 575 - 43
sp_create_replace.sql

@@ -1,32 +1,301 @@
+CREATE OR REPLACE PROCEDURE dashboard_generateScoreYear(pid_evaluacion IN  NUMBER,
+                                             result_code    OUT NUMBER)
+AS
 
 
-CREATE OR REPLACE PROCEDURE P_AVG_PROGRESS_ACTION_PLAN(
-    p_plan_id in integer)
-   as
+    paa_id INT := 0;
 
-     cursor cur_avg (p_plan_id in integer)
-      is
-        select avg(d.AVANCE) avg from plan_accion p
-        join PLAN_ACCION_DET d on p.id = d.PLAN_ACCION_ID
-        and d.PARENT_ID is not null
-        where p.id = p_plan_id;
 
-     L_TOTAL_AVG  NUMBER(5, 2);
+    CURSOR c1 IS
 
-  BEGIN
-    OPEN cur_avg(p_plan_id);
-     FETCH cur_avg INTO L_TOTAL_AVG;
-    CLOSE cur_avg;
+        SELECT e.id     AS id_evaluacion,
+               e.meta   AS meta_evaluacion,
+               e.CALIFICACION,
+               e.CALIFICACION_ANTERIOR,
+               a.id     AS id_area,
+               a.nombre AS nombre_area,
+               a.meta      meta_area,
+               a.kpi_id,
+               k.NOMBRE AS nombre_kpi,
+               c.id     AS id_categoria,
+               c.nombre AS nombre_categoria
+        FROM EVALUACION e
+                 JOIN areas a ON e.AREAS_ID = a.ID
+                 JOIN kpi k ON a.KPI_ID = k.id
+                 LEFT JOIN categorias c ON a.id = c.AREAS_ID;
 
-    update PLAN_ACCION set AVANCE_PROVEEDOR = L_TOTAL_AVG,AVANCE_CM=L_TOTAL_AVG
-    WHERE id =p_plan_id;
+BEGIN
+
+    result_code := 0;
 
- end;
 
+    FOR custom IN c1
+        LOOP
+
+            FOR i IN 1..11
+                LOOP
+                    INSERT INTO EVALUACION_DET (ID,
+                                                COMENTARIO,
+                                                CM_USER_UPDATE,
+                                                VISIBLE_PROVEEDOR,
+                                                CALIFICACION_ANTERIOR,
+                                                CALIFICACION_ACTUAL,
+                                                CALIFICACION_GLOBAL,
+                                                MES,
+                                                CREATED_BY,
+                                                UPDATED_BY,
+                                                CREATED_DATE,
+                                                UPDATED_DATE,
+                                                EVALUACION_ID,
+                                                CATEGORIAS_ID)
+                    VALUES (EV_DETAIL_SEQ.nextval,
+                            'inicial',
+                            'admin',
+                            's',
+                            4.00,
+                            5.00,
+                            6.00,
+                            TO_DATE('2019-' || i || '-25 19:00:00', 'YYYY-MM-DD HH24:MI:SS'),
+                            'admin',
+                            'admin',
+                            current_date,
+                            current_date,
+                            custom.id_evaluacion,
+                            custom.id_categoria);
+                END LOOP;
+
+        END LOOP;
+
+    result_code := 0;
+
+    -- COMMIT;
+
+EXCEPTION WHEN OTHERS
+    THEN
+        result_code := -1;
+        ROLLBACK;
+        RAISE;
+
+
+END;
 ;
+CREATE OR REPLACE PROCEDURE dash_global_by_kpi(pid_kpi     IN  NUMBER,
+                                    result_code OUT NUMBER)
+AS
+
+
+    paa_id INT := 0;
+
+
+BEGIN
+
+    result_code := 0;
+
+
+    MERGE INTO evaluacion_det orig
+    USING (SELECT k.id AS                                   kpi_id,
+                  k.nombre                                  kpi_nombre,
+                  e.id                                      eval_id,
+                  e.CALIFICACION,
+                  e.global,
+                  e.AREAS_ID,
+                  a.nombre                                  area_nombre,
+                  a.meta,
+                  c.ID AS                                   categorias_id,
+                  c.nombre                                  cat_nombre,
+                  c.META_MENSUAL,
+                  (ed.CALIFICACION_ACTUAL / c.META_MENSUAL) global_categoria,
+                  ed.ID                                     detail_id,
+                  to_number(EXTRACT(MONTH FROM ed.mes), 99) mes_number,
+                  ed.CALIFICACION_ANTERIOR,
+                  ed.CALIFICACION_ACTUAL,
+                  ed.CALIFICACION_GLOBAL,
+                  ed.mes                                    fecha
+           FROM EVALUACION_DET ed
+                    JOIN EVALUACION e ON ed.EVALUACION_ID = e.id
+                    JOIN areas a ON e.AREAS_ID = a.id
+                    JOIN categorias c ON ed.CATEGORIAS_ID = c.id
+                    JOIN kpi k ON a.KPI_ID = k.id
+               AND k.id = pid_kpi) detail
+    ON (orig.id = detail.detail_id)
+    WHEN MATCHED THEN UPDATE SET orig.CALIFICACION_GLOBAL = detail.global_categoria;
+
+    COMMIT;
+
+EXCEPTION WHEN OTHERS
+    THEN
+        result_code := -1;
+        ROLLBACK;
+        RAISE;
+
+
+END;
+;
+CREATE OR REPLACE PROCEDURE dash_global_by_kpi_month(pid_kpi     IN  NUMBER,
+                                          pmes        IN  NUMBER,
+                                          result_code OUT NUMBER)
+AS
+
+BEGIN
+
+    result_code := 0;
+
+
+    MERGE INTO evaluacion_det orig
+    USING (SELECT k.id AS                                   kpi_id,
+                  k.nombre                                  kpi_nombre,
+                  e.id                                      eval_id,
+                  e.CALIFICACION,
+                  e.global,
+                  e.AREAS_ID,
+                  a.nombre                                  area_nombre,
+                  a.meta,
+                  c.ID AS                                   categorias_id,
+                  c.nombre                                  cat_nombre,
+                  c.META_MENSUAL,
+                  (ed.CALIFICACION_ACTUAL / c.META_MENSUAL) global_categoria,
+                  ed.ID                                     detail_id,
+                  to_number(EXTRACT(MONTH FROM ed.mes), 99) mes_number,
+                  ed.CALIFICACION_ANTERIOR,
+                  ed.CALIFICACION_ACTUAL,
+                  ed.CALIFICACION_GLOBAL,
+                  ed.mes                                    fecha
+           FROM EVALUACION_DET ed
+                    JOIN EVALUACION e ON ed.EVALUACION_ID = e.id
+                    JOIN areas a ON e.AREAS_ID = a.id
+                    JOIN categorias c ON ed.CATEGORIAS_ID = c.id
+                    JOIN kpi k ON a.KPI_ID = k.id AND k.id = pid_kpi
+           WHERE to_number(EXTRACT(MONTH FROM ed.mes), 99) = pmes) detail
+    ON (orig.id = detail.detail_id)
+    WHEN MATCHED THEN UPDATE SET orig.CALIFICACION_GLOBAL = detail.global_categoria;
+
+    COMMIT;
+
+EXCEPTION
+    WHEN OTHERS
+        THEN
+            result_code := -1;
+            ROLLBACK;
+            RAISE;
+
+
+END;
+;
+CREATE OR REPLACE PROCEDURE d_eval_global_month(pid_kpi     IN  NUMBER, pmes IN NUMBER,
+                                     result_code OUT NUMBER)
+AS
+
+
+    paa_id INT := 0;
+
+
+BEGIN
+
+    result_code := 0;
+
+    MERGE INTO evaluacion orig
+    USING (SELECT k.id id_kpi, e.id id_eval, a.id, avg(ed.CALIFICACION_GLOBAL) AS average
+           FROM EVALUACION_DET ed
+                    JOIN EVALUACION e ON ed.EVALUACION_ID = e.id
+                    JOIN areas a ON e.AREAS_ID = a.id
+                    JOIN categorias c ON ed.CATEGORIAS_ID = c.id
+                    JOIN kpi k ON a.KPI_ID = k.id
+               AND k.id = pid_kpi
+           WHERE to_number(EXTRACT(MONTH FROM ed.mes), 99) = pmes
+           GROUP BY k.id, e.id, a.id, to_number(EXTRACT(MONTH FROM ed.mes), 99)) detail
+    ON (orig.id = detail.id_eval)
+    WHEN MATCHED THEN UPDATE SET orig.GLOBAL = detail.average;
 
+    COMMIT;
 
-create OR REPLACE PROCEDURE pc_create_up_scorecard(p_provider_id IN INTEGER,
+EXCEPTION WHEN OTHERS
+    THEN
+        result_code := -1;
+        ROLLBACK;
+        RAISE;
+
+END;
+;
+CREATE OR REPLACE PROCEDURE get_detail_month(pkpi_id IN NUMBER, pmes IN NUMBER, p_cursor IN OUT SYS_REFCURSOR)
+AS
+BEGIN
+    OPEN p_cursor FOR
+        SELECT k.id AS                                   kpi_id,
+               k.nombre                                  kpi_nombre,
+               e.id                                      eval_id,
+               e.global                                  global_actual,
+               e.AREAS_ID,
+               a.nombre                                  area_nombre,
+               c.ID AS                                   categorias_id,
+               c.nombre                                  cat_nombre,
+               c.META_MENSUAL,
+               (ed.CALIFICACION_ACTUAL / c.META_MENSUAL) global_categoria,
+               ed.ID                                     detail_id,
+               to_number(EXTRACT(MONTH FROM ed.mes), 99) mes_number,
+               ed.CALIFICACION_ACTUAL,
+               ed.CALIFICACION_GLOBAL
+        FROM EVALUACION_DET ed
+                 JOIN EVALUACION e ON ed.EVALUACION_ID = e.id
+                 JOIN areas a ON e.AREAS_ID = a.id
+                 JOIN categorias c ON ed.CATEGORIAS_ID = c.id
+                 JOIN kpi k ON a.KPI_ID = k.id AND k.id = pkpi_id
+        WHERE to_number(EXTRACT(MONTH FROM ed.mes), 99) = pmes
+        ORDER BY k.id, e.id, a.id, c.id, to_number(EXTRACT(MONTH FROM ed.mes), 99);
+
+END;
+;
+CREATE OR REPLACE PROCEDURE get_detail_global(pkpi_id IN NUMBER, p_cursor IN OUT SYS_REFCURSOR)
+AS
+BEGIN
+    OPEN p_cursor FOR
+        SELECT k.id AS                                   kpi_id,
+               k.nombre                                  kpi_nombre,
+               e.id                                      eval_id,
+               e.global                                  global_actual,
+               e.AREAS_ID,
+               a.nombre                                  area_nombre,
+               c.ID AS                                   categorias_id,
+               c.nombre                                  cat_nombre,
+               c.META_MENSUAL,
+               (ed.CALIFICACION_ACTUAL / c.META_MENSUAL) global_categoria,
+               ed.ID                                     detail_id,
+               to_number(EXTRACT(MONTH FROM ed.mes), 99) mes_number,
+               ed.CALIFICACION_ACTUAL,
+               ed.CALIFICACION_GLOBAL
+        FROM EVALUACION_DET ed
+                 JOIN EVALUACION e ON ed.EVALUACION_ID = e.id
+                 JOIN areas a ON e.AREAS_ID = a.id
+                 JOIN categorias c ON ed.CATEGORIAS_ID = c.id
+                 JOIN kpi k ON a.KPI_ID = k.id AND k.id = pkpi_id
+        ORDER BY k.id, e.id, a.id, c.id, to_number(EXTRACT(MONTH FROM ed.mes), 99);
+
+END;
+;
+CREATE OR REPLACE PROCEDURE get_detail_global_month(pkpi_id IN NUMBER, p_cursor IN OUT SYS_REFCURSOR)
+AS
+BEGIN
+    OPEN p_cursor FOR
+        SELECT kpi_id, mes, avg(promedio_area) AS promedio
+        FROM (SELECT k.id AS                                   kpi_id,
+                     e.id                                      eval_id,
+                     a.id                                      areas_id,
+                     to_number(EXTRACT(MONTH FROM ed.mes), 99) mes,
+                     avg(ed.CALIFICACION_GLOBAL)               promedio_area
+              FROM EVALUACION_DET ed
+                       JOIN EVALUACION e ON ed.EVALUACION_ID = e.id
+                       JOIN areas a ON e.AREAS_ID = a.id
+                       JOIN categorias c ON ed.CATEGORIAS_ID = c.id
+                       JOIN kpi k ON a.KPI_ID = k.id AND k.id = pkpi_id
+              GROUP BY k.id, e.id, a.id, to_number(EXTRACT(MONTH FROM ed.mes), 99))
+        GROUP BY kpi_id, mes
+        ORDER BY kpi_id, mes;
+
+END;
+;
+
+
+
+create PROCEDURE pc_create_up_scorecard(p_provider_id IN INTEGER,
                                         p_year        IN INTEGER,
                                         p_month       IN INTEGER)
 IS
@@ -143,13 +412,14 @@ IS
 
   BEGIN
 
+
+
     OPEN cur_score_global(p_provider_id,p_month,p_year);
      FETCH cur_score_global INTO L_TOTAL_AVG,L_NAME;
     CLOSE cur_score_global;
 
     OPEN cur_score_year (p_provider_id,p_month,p_year);
     FETCH cur_score_year INTO L_SCORECARD_PROVIDER_ID, L_LAST_SCORE;
-
     CLOSE cur_score_year;
 
 
@@ -193,6 +463,8 @@ IS
                   ;
         end if;
 
+    delete SCORECARD_PROVIDER_MONTH where SCORECARD_PROVIDER_ID = L_SCORECARD_PROVIDER_ID;
+
     OPEN cur_score_cate(p_provider_id, p_month, p_year);
         LOOP
           FETCH  cur_score_cate INTO L_MONTH,L_YEAR,
@@ -205,40 +477,44 @@ IS
           FETCH cur_score_area INTO L_LAST_SCORE_AREA;
           CLOSE cur_score_area;
 
-         INSERT INTO SCORECARD_PROVIDER_MONTH (ID,
-                                                            MONTH,
-                                                            SCORE,
-                                                            BEFORE_SCORE,
-                                                            SCORE_CATEGORY,
-                                                            BEFORE_SCORE_CATEGORY,
-                                                            CREATED_DATE,
-                                                            SCORECARD_PROVIDER_ID,
-                                                            ESTADO,
-                                                            NOMBRE_AREA,
-                                                            NOMBRE_CATEGORIA,
-                                                            ID_AREA,ID_CATEGORIA)
-            VALUES (scorecard_provider_month_seq.nextval,
-                    L_MONTH,
-                    L_LAST_SCORE_AREA,
-                    L_LAST_SCORE_AREA,
-                    L_LAST_SCORE,
-                    L_LAST_SCORE,
-                    CURRENT_DATE,
-                    L_SCORECARD_PROVIDER_ID,
-                    'NO INICIADO',
-                    L_NOMBRE_AREA,
-                    L_NOMBRE_CATEGORIA,
-                    L_ID_AREA,L_ID_CATEGORIA);
+
+           INSERT INTO SCORECARD_PROVIDER_MONTH (ID,
+                                                              MONTH,
+                                                              SCORE,
+                                                              BEFORE_SCORE,
+                                                              SCORE_CATEGORY,
+                                                              BEFORE_SCORE_CATEGORY,
+                                                              CREATED_DATE,
+                                                              SCORECARD_PROVIDER_ID,
+                                                              ESTADO,
+                                                              NOMBRE_AREA,
+                                                              NOMBRE_CATEGORIA,
+                                                              ID_AREA,ID_CATEGORIA)
+              VALUES (scorecard_provider_month_seq.nextval,
+                      L_MONTH,
+                      L_LAST_SCORE_AREA,
+                      L_LAST_SCORE_AREA,
+                      L_LAST_SCORE,
+                      L_LAST_SCORE,
+                      CURRENT_DATE,
+                      L_SCORECARD_PROVIDER_ID,
+                      'NO INICIADO',
+                      L_NOMBRE_AREA,
+                      L_NOMBRE_CATEGORIA,
+                      L_ID_AREA,L_ID_CATEGORIA);
 
         END LOOP;
     close cur_score_cate;
 
+    delete SCORECARD_PROVIDER_COMMENTS where SCORECARD_PROVIDER_ID = L_SCORECARD_PROVIDER_ID;
+
     OPEN cur_quiz_comments (p_provider_id,p_month,p_year);
     LOOP
       FETCH cur_quiz_comments INTO L_COMMENT_ID,L_COMMENT,L_COMMENT_CREATED_DATE,L_CREATED_BY;
 
       EXIT WHEN cur_quiz_comments%NOTFOUND OR cur_quiz_comments%NOTFOUND IS NULL;
 
+
             INSERT INTO SCORECARD_PROVIDER_COMMENTS (ID,
                                                               COMMENTS,
                                                               CREATED_DATE,
@@ -256,4 +532,260 @@ IS
 
 
   END pc_create_up_scorecard;
+
+  ;
+
+
+
+
+
+CREATE OR REPLACE PROCEDURE GET_RESUME_SCORE_AREA(
+    p_scoreprovider_id IN     SCORECARD_PROVIDER.ID%TYPE
+                                      , p_cursor           IN OUT SYS_REFCURSOR)
+    IS
+
+BEGIN
+    open p_cursor for
+        select s.ID_AREA as idArea, s.nombre_area as name, s.score as score
+        from scorecard_provider_month s
+        where scorecard_provider_id = p_scoreprovider_id
+        group by s.ID_AREA, s.nombre_area, s.score;
+--
+
+END GET_RESUME_SCORE_AREA;
+;
+
+
+CREATE OR REPLACE PROCEDURE GET_RESUME_LASTEST_MONTHS(
+    p_provider_id IN     SCORECARD_PROVIDER.ID%TYPE,
+    p_year in INTEGER,
+    p_cursor      IN OUT SYS_REFCURSOR)
+    IS
+
+BEGIN
+    open p_cursor for
+        select p.MONTH as name, (p.TOTAL_AVG / 5 * 100) as score
+        from scorecard_provider p
+        where p.proveedores_id = p_provider_id
+          and p.year = p_year
+          and p.month > 0
+        order by p.MONTH;
+
+
+END GET_RESUME_LASTEST_MONTHS;
+;
+
+
+CREATE OR REPLACE PROCEDURE GET_SCOREPRO_CATEGORY_SCORES(
+    p_scoreprovider_id IN     SCORECARD_PROVIDER.ID%TYPE,
+    p_area_id          IN     SCORECARD_PROVIDER_MONTH.ID_AREA%TYPE,
+    p_cursor           IN OUT SYS_REFCURSOR)
+    IS
+
+BEGIN
+    open p_cursor for
+        select s.NOMBRE_CATEGORIA as nombre, s.NOMBRE_CATEGORIA as name, s.SCORE_CATEGORY as score
+        from scorecard_provider_month s
+        where s.scorecard_provider_id = p_scoreprovider_id
+          and s.ID_AREA = p_area_id;
+
+
+    --and p.status = 'APROBADO';
+
+
+END GET_SCOREPRO_CATEGORY_SCORES;
+;
+
+
+create OR REPLACE PROCEDURE P_GET_TREND_GLOBAL_MONTH(p_providerId IN NUMBER, p_cursor IN OUT SYS_REFCURSOR)
+AS
+  BEGIN
+    OPEN p_cursor FOR
+
+    select * from scorecard_provider p
+    where p.PROVEEDORES_ID = p_providerId
+    and status ='PUBLICADO'
+    order BY  TO_NUMBER(p.YEAR), TO_NUMBER(p.MONTH) ASC;
+
+
+  END;
+
+
+create OR REPLACE PROCEDURE P_GET_DETAIL_BY_PROVIDER(
+  p_provider_id IN NUMBER,
+  p_year in number,
+  p_cursor IN OUT SYS_REFCURSOR
+)
+AS
+  BEGIN
+    OPEN p_cursor FOR
+    select 1 as kpi_id,
+       m.nombre_area kpi_nombre,
+       1 as evalId,
+       p.TOTAL_AVG global_actual,
+       m.ID_AREA areas_id,
+       m.NOMBRE_AREA area_nombre,
+       m.ID_CATEGORIA categoria_id,
+       m.NOMBRE_CATEGORIA cat_nombre,
+       p.TARGET meta,
+       (m.SCORE_CATEGORY / 5 ) global_categoria,
+       1 detail_id,
+       m.MONTH mes_number,
+       p.YEAR,
+       m.SCORE calificacion_actual,
+       p.LAST_SCORE calificacion_global
+  from SCORECARD_PROVIDER p
+  join SCORECARD_PROVIDER_MONTH m on m.SCORECARD_PROVIDER_ID = p.id
+    where p.PROVEEDORES_ID = p_provider_id
+    and p.TOTAL_AVG  is not null
+    and p.STATUS = 'PUBLICADO'
+  order by TO_NUMBER(p.YEAR),TO_NUMBER(m.MONTH),m.ID_AREA,m.ID_CATEGORIA ;
+
+  END;
+
+CREATE OR REPLACE PROCEDURE P_GET_PROGRESS_ACTION_PLAN(
+  p_providerId IN NUMBER,
+  p_year IN NUMBER,
+  p_cursor IN OUT SYS_REFCURSOR)
+AS
+  BEGIN
+    OPEN p_cursor FOR
+
+    SELECT SUM(AVANCE_CM)/COUNT(*) progress from PLAN_ACCION
+    where PROVEEDOR_ID = p_providerId
+--    AND ESTADO = 'EN PROGRESO'
+--     AND YEAR =
+    GROUP BY PROVEEDOR_ID;
+
+  END;
+
+CREATE OR REPLACE PROCEDURE P_GET_ACTION_PLAN_STATUS(
+  p_providerId IN NUMBER,
+  p_year IN NUMBER,
+  p_cursor IN OUT SYS_REFCURSOR)
+AS
+  BEGIN
+    OPEN p_cursor FOR
+
+    select p.ESTADO,COUNT(*) qty from PLAN_ACCION p
+     where PROVEEDOR_ID = p_providerId
+--     AND YEAR =
+    group by p.ESTADO;
+
+  END;
+
+create OR REPLACE PROCEDURE P_GET_GLOBAL_AVG(
+  p_providerId IN NUMBER,
+  p_year IN NUMBER,
+  p_cursor IN OUT SYS_REFCURSOR)
+AS
+  BEGIN
+    OPEN p_cursor FOR
+
+    select sum(last_score)/count(*) global_avg
+      from SCORECARD_PROVIDER p
+    where p.PROVEEDORES_ID =p_providerId
+      and p.STATUS = 'PUBLICADO'
+    AND p.year = p_year
+    ;
+
+  END;
   ;
+
+CREATE OR REPLACE PROCEDURE P_GET_PEN_QUIZ_USERS( p_cursor IN OUT SYS_REFCURSOR)
+  as
+   BEGIN
+
+     OPEN p_cursor FOR
+        select u.USER_NAME,u.USER_TYPE,p.nombre,p.id
+          from proveedores p
+            join USERS_PROVEEDORES up
+          on up.PROVEEDORES_ID = p.id
+            join users u
+          on u.id = up.USERS_ID
+        where UPPER(u.USER_TYPE) in
+           ('CLIENTE INTERNO')
+          and not exists(
+             select 'x' from EVALUACION_PROVEEDOR ep
+              where ep.CREATED_BY = u.USER_NAME
+              and ep.year = to_char(add_months(sysdate, -1), 'YYYY')
+              and ep.month = to_char(add_months(sysdate, -1), 'MM')
+           )
+      ;
+
+  end;
+;
+
+
+CREATE OR REPLACE PROCEDURE P_GET_PEN_ACTION_EXECUTE( p_cursor IN OUT SYS_REFCURSOR)
+  as
+   BEGIN
+
+      OPEN p_cursor FOR
+        select * from PLAN_ACCION_DET a
+        where a.ESTADO != 'FINALIZADO'
+        and a.FECHA_COMPROMISO<=CURRENT_DATE;
+
+ end;
+;
+
+
+CREATE OR REPLACE PROCEDURE P_GET_HISTORIC_SCORE(
+            p_provider_id in integer,
+            p_year in integer,
+            p_cursor IN OUT SYS_REFCURSOR)
+  as
+   BEGIN
+
+      OPEN p_cursor FOR
+        select p.year,pm.nombre_area,pm.nombre_categoria,
+               '5' META, p.last_score Actual, (p.total_avg*100/5)||'%' Global,
+               nvl(pm.enero,0) ENERO,nvl(pm.FEBRERO,0) Febrero,nvl(pm.marzo,0) Marzo,
+               nvl(pm.abril,0) Abril,nvl(pm.mayo,0) Mayo,
+               nvl(pm.junio,0) Junio,nvl(pm.julio,0) Julio,
+               nvl(pm.AGOSTO,0) Agosto,nvl(pm.SEPTIEMBRE,0) Septiembre,
+               nvl(pm.OCTUBRE,0) Octubre,nvl(pm.NOVIEMBRE,0) Noviembre,nvl(pm.DICIEMBRE,0) DICIEMBRE
+              from (
+                select *
+                   from SOCRECARDNEW.SCORECARD_PROVIDER_MONTH
+                   PIVOT(
+                    sum(nvl(score,0))
+                    FOR month
+                    IN (
+                        '1' Enero,'2' Febrero,'3' Marzo,'4' Abril,'5' Mayo,'6' Junio,'7' Julio,
+                        '8' Agosto,'9' Septiembre,'10' Octubre,'11' Noviembre,'12' Diciembre
+                    )
+                )) pm join SOCRECARDNEW.SCORECARD_PROVIDER p on p.id = pm.scorecard_provider_id
+            where p.proveedores_id = p_provider_id
+            and p.year = p_year
+          order by pm.nombre_area;
+
+ end;
+;
+
+CREATE OR REPLACE PROCEDURE P_AVG_PROGRESS_ACTION_PLAN(
+    p_plan_id in integer)
+   as
+
+     cursor cur_avg (p_plan_id in integer)
+      is
+        select avg(d.AVANCE) avg from plan_accion p
+        join PLAN_ACCION_DET d on p.id = d.PLAN_ACCION_ID
+        and d.PARENT_ID is not null
+        where p.id = p_plan_id;
+
+     L_TOTAL_AVG  NUMBER(5, 2);
+
+  BEGIN
+    OPEN cur_avg(p_plan_id);
+     FETCH cur_avg INTO L_TOTAL_AVG;
+    CLOSE cur_avg;
+
+    update PLAN_ACCION set AVANCE_PROVEEDOR = L_TOTAL_AVG,AVANCE_CM=L_TOTAL_AVG
+    WHERE id =p_plan_id;
+
+ end;
+
+;
+
+