yxqvalid.sql 12 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226
  1. create or replace
  2. PROCEDURE YXQVALID
  3. ( WARN_DAYS IN NUMBER --提前提醒天数
  4. , ADMIN_ID IN NUMBER --管理员ID
  5. , TXNR1 IN VARCHAR2 --即将过期的提醒内容
  6. , TXNR2 IN VARCHAR2 --已经过期的提醒内容
  7. , TXNR3 IN VARCHAR2 --附证第一次年审的提醒内容
  8. , TXNR4 IN VARCHAR2 --附证第二次年审的提醒内容
  9. , BUS_TYPE_JYR IN VARCHAR2 --附证过期提醒类型
  10. , BUS_TYPE_NS IN VARCHAR2 --年审提醒类型
  11. , BUS_TYPE_ZC IN VARCHAR2 --自查提醒类型
  12. , BUS_TYPE_DC IN VARCHAR2 --督查提醒类型
  13. , BUS_TYPE_JYRZYCS_DC IN VARCHAR2 --经营人作业场所提醒类型
  14. , ROLE_TYPE_DC IN VARCHAR2 --督查人员类型
  15. , SZD IN NUMBER --所在地
  16. ) AS
  17. BEGIN
  18. DECLARE
  19. strsql VARCHAR2(500); --执行语句
  20. JYR_ID NUMBER; --经营人ID
  21. JYR_BAFZRQ DATE; --经营人附证到期日期
  22. ZC_ID NUMBER; --自查ID
  23. DC_ID NUMBER; --督查ID
  24. GKJYR VARCHAR2(200); --港口经营人名称
  25. DCDW VARCHAR2(100); --港口经营人名称
  26. JCSJ VARCHAR2(20); --检查时间
  27. USER_ID NUMBER; --用户ID
  28. GZTX_SIZE NUMBER; --工作提醒条数
  29. TXNR VARCHAR2(500); --提醒内容
  30. CURSOR CUR_EXPIRED_FZ IS
  31. SELECT ID,BAFZRQ FROM T_YJPT_JYRJCXX WHERE BAFZRQ<TRUNC(SYSDATE, 'DD')-WARN_DAYS AND RECORD_STATUS<>9; --附证过期的经营人
  32. CURSOR CUR_NS_JYR_1 IS
  33. SELECT ID FROM T_YJPT_JYRJCXX jyr WHERE jyr.RECORD_STATUS<>9
  34. AND EXISTS (SELECT 1 FROM T_YJPT_GKWXHWZYFZBLHHZ hz WHERE hz.JYR=jyr.ID AND hz.RECORD_STATUS =2 AND hz.FZSJ IS NOT NULL AND ADD_MONTHS(hz.FZSJ,13)>SYSDATE AND ADD_MONTHS(hz.FZSJ,12)<SYSDATE
  35. AND HZ.BYZD1 NOT IN (SELECT NS.FZBH FROM T_YJPT_JYRXX_NSB NS WHERE NS.JYR=jyr.ID AND NS.NSNS=1 AND NS.RECORD_STATUS<>9));--需要进行第一次年审的经营人
  36. CURSOR CUR_NS_JYR_2 IS
  37. SELECT ID FROM T_YJPT_JYRJCXX jyr WHERE jyr.RECORD_STATUS<>9
  38. AND EXISTS (SELECT 1 FROM T_YJPT_GKWXHWZYFZBLHHZ hz WHERE hz.JYR=jyr.ID AND hz.RECORD_STATUS =2 AND hz.FZSJ IS NOT NULL AND ADD_MONTHS(hz.FZSJ,25)>SYSDATE AND ADD_MONTHS(hz.FZSJ,24)<SYSDATE
  39. AND HZ.BYZD1 NOT IN (SELECT NS.FZBH FROM T_YJPT_JYRXX_NSB NS WHERE NS.JYR=jyr.ID AND NS.NSNS=2AND NS.RECORD_STATUS<>9)); --需要进行第二次年审的经营人
  40. CURSOR CUR_EXPIRED_ZC IS
  41. SELECT zc.ID,jyr.ID,jyr.GKJYR,TO_CHAR(zc.JCSJ,'yyyy-mm-dd') FROM T_YJPT_ZCYH yh JOIN T_YJPT_ZC zc ON yh.SSZC= zc.ID JOIN T_YJPT_JYRJCXX jyr ON zc.QYMC=jyr.ID
  42. WHERE yh.JHWCSJ<=TRUNC(SYSDATE, 'DD') AND yh.MQZT='-1' AND yh.RECORD_STATUS<>9 AND zc.RECORD_STATUS<>9 AND jyr.RECORD_STATUS<>9; --到期的自查隐患
  43. CURSOR CUR_EXPIRED_DC IS
  44. SELECT dc.ID,jyr.ID,jyr.GKJYR,TO_CHAR(dc.SJ,'yyyy-mm-dd'),dc.DCDW FROM T_YJPT_DC dc JOIN T_YJPT_JYRJCXX jyr ON dc.BDCDW=jyr.ID
  45. WHERE dc.JHWCSJ<=TRUNC(SYSDATE, 'DD') AND dc.MQZT='-1' AND dc.RECORD_STATUS<>9 AND jyr.RECORD_STATUS<>9; --到期的督查
  46. CURSOR CUR_EXPIRED_ZYCS IS
  47. SELECT distinct jyr.ID,jyr.GKJYR FROM T_YJPT_DC dc JOIN T_YJPT_JYRJCXX jyr ON dc.BDCDW=jyr.ID
  48. WHERE dc.JHWCSJ<=TRUNC(SYSDATE, 'DD') AND dc.MQZT='-1' AND dc.RECORD_STATUS<>9 AND jyr.RECORD_STATUS<>9; --到期的督查
  49. CURSOR CUR_JYR_ADMIN(JYRID IN NUMBER) IS
  50. SELECT DISTINCT u.ID FROM T_YJPT_USER u WHERE RECORD_STATUS<>9 AND JYRRYXXID=JYRID AND EXISTS (SELECT 1 FROM T_YJPT_ROLE_USER ru WHERE ru.USERID= u.ID AND ru.ROLEID=2); --经营人管理员
  51. CURSOR CUR_ROLE_USER(R_TYPE IN VARCHAR2) IS
  52. SELECT DISTINCT u.ID FROM T_YJPT_USER u WHERE RECORD_STATUS<>9
  53. AND EXISTS (SELECT 1 FROM T_YJPT_ROLE_USER ru JOIN T_YJPT_ROLE r ON ru.ROLEID=r.ID WHERE ru.USERID= u.ID AND r.ROLE_TYPE=R_TYPE); --督查类型人员
  54. BEGIN
  55. --附证到期提醒
  56. OPEN CUR_EXPIRED_FZ;
  57. LOOP
  58. FETCH CUR_EXPIRED_FZ
  59. INTO JYR_ID,JYR_BAFZRQ;
  60. EXIT WHEN CUR_EXPIRED_FZ%NOTFOUND;
  61. OPEN CUR_JYR_ADMIN(JYR_ID);
  62. LOOP
  63. FETCH CUR_JYR_ADMIN
  64. INTO USER_ID;
  65. EXIT WHEN CUR_JYR_ADMIN%NOTFOUND;
  66. --附证到期提醒是否存在
  67. strsql := 'SELECT COUNT(*) FROM T_YJPT_GZTX WHERE BDID='||JYR_ID||' AND BUSTYPE='''||BUS_TYPE_JYR||''' AND JSR='||USER_ID||' AND TXZT=''Y''';
  68. --DBMS_OUTPUT.PUT_LINE(strsql);
  69. EXECUTE IMMEDIATE strsql into GZTX_SIZE;
  70. IF(GZTX_SIZE=0) THEN
  71. IF(JYR_BAFZRQ<SYSDATE) THEN
  72. TXNR := TXNR1;
  73. ELSE
  74. TXNR := TXNR2;
  75. END IF;
  76. --插入附证到期提醒
  77. strsql := 'INSERT INTO T_YJPT_GZTX (ID,TXSJ,TXZT,TXNR,BDID,JSR,FSR,ADD_USER,ADD_DATE,RECORD_STATUS,BYZD5,BUSTYPE,SZD)'
  78. ||'VALUES ('||SYS_SEQUENCE.nextval||',SYSDATE,''Y'','''||TXNR||''','||JYR_ID||','||USER_ID||','||ADMIN_ID||','||ADMIN_ID||',SYSDATE,1,''N'','''||BUS_TYPE_JYR||''','||SZD||')';
  79. --DBMS_OUTPUT.PUT_LINE(strsql);
  80. EXECUTE IMMEDIATE strsql;
  81. END IF;
  82. END LOOP;
  83. CLOSE CUR_JYR_ADMIN;
  84. END LOOP;
  85. CLOSE CUR_EXPIRED_FZ;
  86. COMMIT;
  87. --年审到期提醒
  88. OPEN CUR_NS_JYR_1;
  89. LOOP
  90. FETCH CUR_NS_JYR_1
  91. INTO JYR_ID;
  92. EXIT WHEN CUR_NS_JYR_1%NOTFOUND;
  93. OPEN CUR_JYR_ADMIN(JYR_ID);
  94. LOOP
  95. FETCH CUR_JYR_ADMIN
  96. INTO USER_ID;
  97. EXIT WHEN CUR_JYR_ADMIN%NOTFOUND;
  98. --第一次年审到期提醒是否存在
  99. strsql := 'SELECT COUNT(*) FROM T_YJPT_GZTX WHERE BDID='||JYR_ID||' AND BUSTYPE='''||BUS_TYPE_NS||''' AND TXNR='''||TXNR3||''' AND JSR='||USER_ID||' AND TXZT=''Y''';
  100. --DBMS_OUTPUT.PUT_LINE(strsql);
  101. EXECUTE IMMEDIATE strsql into GZTX_SIZE;
  102. IF(GZTX_SIZE=0) THEN
  103. --插入第一次年审到期提醒
  104. strsql := 'INSERT INTO T_YJPT_GZTX (ID,TXSJ,TXZT,TXNR,BDID,JSR,FSR,ADD_USER,ADD_DATE,RECORD_STATUS,BYZD5,BUSTYPE,SZD)'
  105. ||'VALUES ('||SYS_SEQUENCE.nextval||',SYSDATE,''Y'','''||TXNR3||''','||JYR_ID||','||USER_ID||','||ADMIN_ID||','||ADMIN_ID||',SYSDATE,1,''N'','''||BUS_TYPE_NS||''','||SZD||')';
  106. --DBMS_OUTPUT.PUT_LINE(strsql);
  107. EXECUTE IMMEDIATE strsql;
  108. END IF;
  109. END LOOP;
  110. CLOSE CUR_JYR_ADMIN;
  111. END LOOP;
  112. CLOSE CUR_NS_JYR_1;
  113. OPEN CUR_NS_JYR_2;
  114. LOOP
  115. FETCH CUR_NS_JYR_2
  116. INTO JYR_ID;
  117. EXIT WHEN CUR_NS_JYR_2%NOTFOUND;
  118. OPEN CUR_JYR_ADMIN(JYR_ID);
  119. LOOP
  120. FETCH CUR_JYR_ADMIN
  121. INTO USER_ID;
  122. EXIT WHEN CUR_JYR_ADMIN%NOTFOUND;
  123. --第二次年审到期提醒是否存在
  124. strsql := 'SELECT COUNT(*) FROM T_YJPT_GZTX WHERE BDID='||JYR_ID||' AND BUSTYPE='''||BUS_TYPE_NS||''' AND TXNR='''||TXNR4||''' AND JSR='||USER_ID||' AND TXZT=''Y''';
  125. --DBMS_OUTPUT.PUT_LINE(strsql);
  126. EXECUTE IMMEDIATE strsql into GZTX_SIZE;
  127. IF(GZTX_SIZE=0) THEN
  128. --插入第二次年审到期提醒
  129. strsql := 'INSERT INTO T_YJPT_GZTX (ID,TXSJ,TXZT,TXNR,BDID,JSR,FSR,ADD_USER,ADD_DATE,RECORD_STATUS,BYZD5,BUSTYPE,SZD)'
  130. ||'VALUES ('||SYS_SEQUENCE.nextval||',SYSDATE,''Y'','''||TXNR4||''','||JYR_ID||','||USER_ID||','||ADMIN_ID||','||ADMIN_ID||',SYSDATE,1,''N'','''||BUS_TYPE_NS||''','||SZD||')';
  131. --DBMS_OUTPUT.PUT_LINE(strsql);
  132. EXECUTE IMMEDIATE strsql;
  133. END IF;
  134. END LOOP;
  135. CLOSE CUR_JYR_ADMIN;
  136. END LOOP;
  137. CLOSE CUR_NS_JYR_2;
  138. COMMIT;
  139. --自查隐患到期提醒
  140. OPEN CUR_EXPIRED_ZC;
  141. LOOP
  142. FETCH CUR_EXPIRED_ZC
  143. INTO ZC_ID,JYR_ID,GKJYR,JCSJ;
  144. EXIT WHEN CUR_EXPIRED_ZC%NOTFOUND;
  145. OPEN CUR_JYR_ADMIN(JYR_ID);
  146. LOOP
  147. FETCH CUR_JYR_ADMIN
  148. INTO USER_ID;
  149. EXIT WHEN CUR_JYR_ADMIN%NOTFOUND;
  150. --自查隐患到期提醒是否存在
  151. strsql := 'SELECT COUNT(*) FROM T_YJPT_GZTX WHERE BDID='||ZC_ID||' AND BUSTYPE='''||BUS_TYPE_ZC||''' AND JSR='||USER_ID||' AND TXZT=''Y''';
  152. --DBMS_OUTPUT.PUT_LINE(strsql);
  153. EXECUTE IMMEDIATE strsql into GZTX_SIZE;
  154. IF(GZTX_SIZE=0) THEN
  155. --插入自查隐患到期提醒
  156. strsql := 'INSERT INTO T_YJPT_GZTX (ID,TXSJ,TXZT,TXNR,BDID,JSR,FSR,ADD_USER,ADD_DATE,RECORD_STATUS,BYZD5,BUSTYPE,SZD)'
  157. ||'VALUES ('||SYS_SEQUENCE.nextval||',SYSDATE,''Y'','''||GKJYR||'于'||JCSJ||'查出的隐患未整改'','
  158. ||ZC_ID||','||USER_ID||','||ADMIN_ID||','||ADMIN_ID||',SYSDATE,1,''N'','''||BUS_TYPE_ZC||''','||SZD||')';
  159. --DBMS_OUTPUT.PUT_LINE(strsql);
  160. EXECUTE IMMEDIATE strsql;
  161. END IF;
  162. END LOOP;
  163. CLOSE CUR_JYR_ADMIN;
  164. END LOOP;
  165. CLOSE CUR_EXPIRED_ZC;
  166. COMMIT;
  167. --督查隐患到期提醒
  168. OPEN CUR_EXPIRED_DC;
  169. LOOP
  170. FETCH CUR_EXPIRED_DC
  171. INTO DC_ID,JYR_ID,GKJYR,JCSJ,DCDW;
  172. EXIT WHEN CUR_EXPIRED_DC%NOTFOUND;
  173. --删除督查隐患到期提醒
  174. strsql := 'DELETE FROM T_YJPT_GZTX WHERE BDID='||DC_ID||' AND BUSTYPE='''||BUS_TYPE_DC||''' AND TXZT=''Y''';
  175. --DBMS_OUTPUT.PUT_LINE(strsql);
  176. EXECUTE IMMEDIATE strsql;
  177. OPEN CUR_JYR_ADMIN(JYR_ID);
  178. LOOP
  179. FETCH CUR_JYR_ADMIN
  180. INTO USER_ID;
  181. EXIT WHEN CUR_JYR_ADMIN%NOTFOUND;
  182. --插入督查隐患到期提醒
  183. strsql := 'INSERT INTO T_YJPT_GZTX (ID,TXSJ,TXZT,TXNR,BDID,JSR,FSR,ADD_USER,ADD_DATE,RECORD_STATUS,BYZD5,BUSTYPE,SZD)'
  184. ||'VALUES ('||SYS_SEQUENCE.nextval||',SYSDATE,''Y'','''||DCDW||'于'||JCSJ||'对'||GKJYR||'进行监督检查,所查隐患记录未整改'','
  185. ||DC_ID||','||USER_ID||','||ADMIN_ID||','||ADMIN_ID||',SYSDATE,1,''N'','''||BUS_TYPE_DC||''','||SZD||')';
  186. --DBMS_OUTPUT.PUT_LINE(strsql);
  187. EXECUTE IMMEDIATE strsql;
  188. END LOOP;
  189. CLOSE CUR_JYR_ADMIN;
  190. END LOOP;
  191. CLOSE CUR_EXPIRED_DC;
  192. COMMIT;
  193. --禁止作业-督查隐患
  194. OPEN CUR_EXPIRED_ZYCS;
  195. LOOP
  196. FETCH CUR_EXPIRED_ZYCS
  197. INTO JYR_ID,GKJYR;
  198. EXIT WHEN CUR_EXPIRED_ZYCS%NOTFOUND;
  199. --删除禁止作业-督查隐患提醒
  200. strsql := 'DELETE FROM T_YJPT_GZTX WHERE BDID='||JYR_ID||' AND BUSTYPE='''||BUS_TYPE_JYRZYCS_DC||''' AND TXZT=''Y''';
  201. --DBMS_OUTPUT.PUT_LINE(strsql);
  202. EXECUTE IMMEDIATE strsql;
  203. OPEN CUR_ROLE_USER(ROLE_TYPE_DC);
  204. LOOP
  205. FETCH CUR_ROLE_USER
  206. INTO USER_ID;
  207. EXIT WHEN CUR_ROLE_USER%NOTFOUND;
  208. --插入禁止作业-督查隐患提醒
  209. strsql := 'INSERT INTO T_YJPT_GZTX (ID,TXSJ,TXZT,TXNR,BDID,JSR,FSR,ADD_USER,ADD_DATE,RECORD_STATUS,BYZD5,BUSTYPE,SZD)'
  210. ||'VALUES ('||SYS_SEQUENCE.nextval||',SYSDATE,''Y'','''||GKJYR||'的企业隐患在限期整改'||TO_CHAR(SYSDATE,'yyyy-mm-dd')||'前未完成,请设置该企业的作业场所禁止进行危货作业申报'','
  211. ||JYR_ID||','||USER_ID||','||ADMIN_ID||','||ADMIN_ID||',SYSDATE,1,''N'','''||BUS_TYPE_JYRZYCS_DC||''','||SZD||')';
  212. --DBMS_OUTPUT.PUT_LINE(strsql);
  213. EXECUTE IMMEDIATE strsql;
  214. END LOOP;
  215. CLOSE CUR_ROLE_USER;
  216. END LOOP;
  217. CLOSE CUR_EXPIRED_ZYCS;
  218. COMMIT;
  219. END;
  220. END YXQVALID;