sp_create_replace.sql 10 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259
  1. CREATE OR REPLACE PROCEDURE P_AVG_PROGRESS_ACTION_PLAN(
  2. p_plan_id in integer)
  3. as
  4. cursor cur_avg (p_plan_id in integer)
  5. is
  6. select avg(d.AVANCE) avg from plan_accion p
  7. join PLAN_ACCION_DET d on p.id = d.PLAN_ACCION_ID
  8. and d.PARENT_ID is not null
  9. where p.id = p_plan_id;
  10. L_TOTAL_AVG NUMBER(5, 2);
  11. BEGIN
  12. OPEN cur_avg(p_plan_id);
  13. FETCH cur_avg INTO L_TOTAL_AVG;
  14. CLOSE cur_avg;
  15. update PLAN_ACCION set AVANCE_PROVEEDOR = L_TOTAL_AVG,AVANCE_CM=L_TOTAL_AVG
  16. WHERE id =p_plan_id;
  17. end;
  18. ;
  19. create OR REPLACE PROCEDURE pc_create_up_scorecard(p_provider_id IN INTEGER,
  20. p_year IN INTEGER,
  21. p_month IN INTEGER)
  22. IS
  23. CURSOR cur_score_cate (p_provider_id IN scorecard_PROVIDER.PROVEEDORES_ID%TYPE,
  24. p_month IN SCORECARD_PROVIDER_MONTH.MONTH%TYPE,
  25. p_year IN scorecard_PROVIDER.YEAR%TYPE) is
  26. SELECT to_number(EXTRACT(MONTH FROM ed.mes), 99) mes,
  27. to_number(EXTRACT(YEAR FROM ed.mes), 9999) YEAR,
  28. p.NOMBRE,a.NOMBRE,c.NOMBRE,
  29. p.id,
  30. a.ID,c.id,
  31. avg(ed.CALIFICACION_ACTUAL) promedio_area
  32. FROM EVALUACION_DET ed
  33. JOIN EVALUACION e ON ed.EVALUACION_ID = e.id
  34. JOIN areas a ON e.AREAS_ID = a.id
  35. JOIN categorias c ON ed.CATEGORIAS_ID = c.id
  36. JOIN kpi k ON a.KPI_ID = k.id
  37. JOIN PROVEEDORES P on e.PROVEEDORES_ID = P.ID
  38. WHERE p.id = p_provider_id
  39. AND to_number(EXTRACT(MONTH FROM ed.mes), 99) = p_month
  40. AND to_number(EXTRACT(year FROM ed.mes), 9999) = p_year
  41. GROUP BY to_number(EXTRACT(MONTH FROM ed.mes), 99),
  42. to_number(EXTRACT(YEAR FROM ed.mes), 9999),
  43. p.NOMBRE,a.NOMBRE,c.NOMBRE,
  44. p.id,
  45. a.ID,c.id
  46. order by mes;
  47. CURSOR cur_score_area (
  48. p_provider_id scorecard_PROVIDER.PROVEEDORES_ID%TYPE,
  49. p_month SCORECARD_PROVIDER_MONTH.MONTH%TYPE,
  50. p_year scorecard_PROVIDER.YEAR%TYPE,
  51. p_area_id IN scorecard_PROVIDER.YEAR%TYPE) is
  52. SELECT avg(ed.CALIFICACION_ACTUAL)
  53. FROM EVALUACION_DET ed
  54. JOIN EVALUACION e ON ed.EVALUACION_ID = e.id
  55. JOIN areas a ON e.AREAS_ID = a.id
  56. JOIN categorias c ON ed.CATEGORIAS_ID = c.id
  57. JOIN PROVEEDORES P on e.PROVEEDORES_ID = P.ID
  58. WHERE p.id = p_provider_id
  59. AND to_number(EXTRACT(MONTH FROM ed.mes), 99) = p_month
  60. AND to_number(EXTRACT(year FROM ed.mes), 9999) = p_year
  61. and a.id = p_area_id;
  62. CURSOR cur_score_global (p_provider_id scorecard_PROVIDER.PROVEEDORES_ID%TYPE,
  63. p_month SCORECARD_PROVIDER_MONTH.MONTH%TYPE,
  64. p_year scorecard_PROVIDER.YEAR%TYPE) is
  65. select avg(promedio_categoria),NOMBRE
  66. from (SELECT e.id eval_id,
  67. c.id categoria_id,
  68. to_number(EXTRACT(MONTH FROM ed.mes), 99) mes,
  69. to_number(EXTRACT(YEAR FROM ed.mes), 9999) YEAR,
  70. p.NOMBRE,
  71. p.id provedorId,
  72. avg(ed.CALIFICACION_ACTUAL) promedio_categoria
  73. FROM EVALUACION_DET ed
  74. JOIN EVALUACION e ON ed.EVALUACION_ID = e.id
  75. JOIN categorias c ON ed.CATEGORIAS_ID = c.id
  76. JOIN PROVEEDORES P on e.PROVEEDORES_ID = P.ID
  77. where p.id = p_provider_id
  78. and to_number(EXTRACT(MONTH FROM ed.mes), 99) = p_month
  79. AND to_number(EXTRACT(year FROM ed.mes), 9999) = p_year
  80. GROUP BY e.id, c.id, p.nombre, p.id, to_number(EXTRACT(MONTH FROM ed.mes), 99),
  81. to_number(EXTRACT(YEAR FROM ed.mes), 9999))
  82. group by YEAR, NOMBRE, provedorId; --mes,
  83. CURSOR cur_score_year (
  84. p_provider_id scorecard_PROVIDER.PROVEEDORES_ID%TYPE,
  85. p_month IN SCORECARD_PROVIDER_MONTH.MONTH%TYPE,
  86. p_year scorecard_PROVIDER.YEAR%TYPE) is
  87. select p.id, p.LAST_SCORE
  88. from SCORECARD_PROVIDER p
  89. where p.PROVEEDORES_ID = p_provider_id
  90. and p.YEAR = p_year
  91. and p.MONTH = p_month;
  92. CURSOR cur_quiz_comments
  93. (p_provider_id scorecard_PROVIDER.PROVEEDORES_ID%TYPE,
  94. p_month SCORECARD_PROVIDER_MONTH.MONTH%TYPE,
  95. p_year scorecard_PROVIDER.YEAR%TYPE)
  96. is
  97. select d.id,d.comentario,d.CREATED_DATE,d.CREATED_BY
  98. from EVALUACION_DET_COMMENTARIOS d
  99. join evaluacion_det e on e.id =d.EVALUACION_DET_ID
  100. join evaluacion x on x.id = e.EVALUACION_ID
  101. and x.PROVEEDORES_ID = p_provider_id
  102. and to_number(EXTRACT(MONTH FROM e.mes), 99) = p_month
  103. AND to_number(EXTRACT(year FROM e.mes), 9999) = p_year;
  104. L_NAME scorecard_PROVIDER.NAME%TYPE;
  105. L_LAST_SCORE_AREA SCORECARD_PROVIDER_MONTH.SCORE%TYPE;
  106. L_LAST_SCORE scorecard_PROVIDER.LAST_SCORE%TYPE; -- CATGORIAS
  107. L_BEFORE_SCORE scorecard_PROVIDER.BEFORE_SCORE%TYPE;
  108. L_TOTAL_AVG scorecard_PROVIDER.TOTAL_AVG%TYPE;
  109. L_TARGET scorecard_PROVIDER.TARGET%TYPE:=5;
  110. L_YEAR scorecard_PROVIDER.YEAR%TYPE:=p_year;
  111. L_CREATED_DATE scorecard_PROVIDER.CREATED_DATE%TYPE;
  112. L_PROVEEDORES_ID scorecard_PROVIDER.PROVEEDORES_ID%TYPE:=p_provider_id;
  113. L_SCORECARD_PROVIDER SCORECARD_PROVIDER.PROVEEDORES_ID%TYPE;
  114. L_MONTH SCORECARD_PROVIDER_MONTH.MONTH%TYPE:=p_month;
  115. L_SCORECARD_PROVIDER_ID SCORECARD_PROVIDER.ID%TYPE;
  116. L_NOMBRE_AREA scorecard_PROVIDER_MONTH.NOMBRE_AREA%TYPE;
  117. L_NOMBRE_CATEGORIA scorecard_PROVIDER_MONTH.NOMBRE_CATEGORIA%TYPE;
  118. L_ID_AREA AREAS.ID%TYPE;
  119. L_ID_CATEGORIA CATEGORIAS.ID%TYPE;
  120. L_COMMENT EVALUACION_DET_COMMENTARIOS.COMENTARIO%TYPE;
  121. L_COMMENT_ID EVALUACION_DET_COMMENTARIOS.ID%TYPE;
  122. L_COMMENT_CREATED_DATE EVALUACION_DET_COMMENTARIOS.CREATED_DATE%TYPE;
  123. L_CREATED_BY EVALUACION_DET_COMMENTARIOS.CREATED_BY%TYPE;
  124. BEGIN
  125. OPEN cur_score_global(p_provider_id,p_month,p_year);
  126. FETCH cur_score_global INTO L_TOTAL_AVG,L_NAME;
  127. CLOSE cur_score_global;
  128. OPEN cur_score_year (p_provider_id,p_month,p_year);
  129. FETCH cur_score_year INTO L_SCORECARD_PROVIDER_ID, L_LAST_SCORE;
  130. CLOSE cur_score_year;
  131. if L_SCORECARD_PROVIDER_ID > 0
  132. then
  133. UPDATE SCORECARD_PROVIDER
  134. SET NAME = L_NAME,
  135. LAST_SCORE = L_TOTAL_AVG,
  136. BEFORE_SCORE = L_BEFORE_SCORE,
  137. TOTAL_AVG = L_TOTAL_AVG,
  138. TARGET = L_TARGET,
  139. YEAR = L_YEAR,
  140. UPDATED_DATE = CURRENT_DATE
  141. WHERE ID = L_SCORECARD_PROVIDER_ID;
  142. else
  143. L_SCORECARD_PROVIDER_ID := scorecard_provider_seq.nextval;
  144. INSERT INTO SCORECARD_PROVIDER (ID,
  145. NAME,
  146. LAST_SCORE,
  147. BEFORE_SCORE,
  148. TOTAL_AVG,
  149. TARGET,
  150. YEAR,
  151. CREATED_DATE,
  152. PROVEEDORES_ID,
  153. STATUS,
  154. MONTH)
  155. values( L_SCORECARD_PROVIDER_ID,
  156. L_NAME,
  157. L_TOTAL_AVG,
  158. 0,
  159. L_TOTAL_AVG,--L_LAST_SCORE,
  160. L_TARGET,--L_BEFORE_SCORE,
  161. p_year,
  162. CURRENT_DATE,
  163. p_provider_id,
  164. 'NO INICIADO',
  165. p_month)
  166. ;
  167. end if;
  168. OPEN cur_score_cate(p_provider_id, p_month, p_year);
  169. LOOP
  170. FETCH cur_score_cate INTO L_MONTH,L_YEAR,
  171. L_NAME,L_NOMBRE_AREA,L_NOMBRE_CATEGORIA,L_PROVEEDORES_ID,L_ID_AREA,L_ID_CATEGORIA,
  172. L_LAST_SCORE;
  173. EXIT WHEN cur_score_cate%NOTFOUND OR cur_score_cate%NOTFOUND IS NULL;
  174. open cur_score_area(p_provider_id, p_month, p_year,L_ID_AREA);--nota agrupada de las categorias al area
  175. FETCH cur_score_area INTO L_LAST_SCORE_AREA;
  176. CLOSE cur_score_area;
  177. INSERT INTO SCORECARD_PROVIDER_MONTH (ID,
  178. MONTH,
  179. SCORE,
  180. BEFORE_SCORE,
  181. SCORE_CATEGORY,
  182. BEFORE_SCORE_CATEGORY,
  183. CREATED_DATE,
  184. SCORECARD_PROVIDER_ID,
  185. ESTADO,
  186. NOMBRE_AREA,
  187. NOMBRE_CATEGORIA,
  188. ID_AREA,ID_CATEGORIA)
  189. VALUES (scorecard_provider_month_seq.nextval,
  190. L_MONTH,
  191. L_LAST_SCORE_AREA,
  192. L_LAST_SCORE_AREA,
  193. L_LAST_SCORE,
  194. L_LAST_SCORE,
  195. CURRENT_DATE,
  196. L_SCORECARD_PROVIDER_ID,
  197. 'NO INICIADO',
  198. L_NOMBRE_AREA,
  199. L_NOMBRE_CATEGORIA,
  200. L_ID_AREA,L_ID_CATEGORIA);
  201. END LOOP;
  202. close cur_score_cate;
  203. OPEN cur_quiz_comments (p_provider_id,p_month,p_year);
  204. LOOP
  205. FETCH cur_quiz_comments INTO L_COMMENT_ID,L_COMMENT,L_COMMENT_CREATED_DATE,L_CREATED_BY;
  206. EXIT WHEN cur_quiz_comments%NOTFOUND OR cur_quiz_comments%NOTFOUND IS NULL;
  207. INSERT INTO SCORECARD_PROVIDER_COMMENTS (ID,
  208. COMMENTS,
  209. CREATED_DATE,
  210. CREATED_USER,
  211. SCORECARD_PROVIDER_ID)
  212. VALUES (L_COMMENT_ID,
  213. L_COMMENT,
  214. L_COMMENT_CREATED_DATE,
  215. L_CREATED_BY,
  216. L_SCORECARD_PROVIDER_ID
  217. );
  218. END LOOP ;
  219. CLOSE cur_quiz_comments;
  220. END pc_create_up_scorecard;
  221. ;