section.xml 33 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721
  1. <?xml version="1.0" encoding="UTF-8"?>
  2. <!DOCTYPE mapper PUBLIC "-//mybatis.org//DTD Mapper 3.0//EN" "http://mybatis.org/dtd/mybatis-3-mapper.dtd">
  3. <mapper namespace="com.tsi.monitoring.mapper.section.SectionMapper">
  4. <!-- 센터정보 -->
  5. <select id="getCenterInfo" resultType="com.tsi.monitoring.vo.CenterVo">
  6. SELECT A.CENTERID AS CENTER_ID,
  7. CENTERINFO AS CENTER_INFO,
  8. IPADDRESS AS IP_ADDRESS,
  9. NVL(COMMPORT, 0) AS COMM_PORT
  10. FROM CENTER A
  11. WHERE CENTERFLAG != 'M'
  12. ORDER BY CENTER_ID
  13. </select>
  14. <!-- 연계센터 정보 -->
  15. <select id="getMCenterInfo" resultType="com.tsi.monitoring.vo.MCenterVo">
  16. SELECT MCENTERID AS M_CENTER_ID, CENTER_NAME, IP_ADDRESS
  17. FROM CENTER_INFO@EXT12LOCDB
  18. ORDER BY M_CENTER_ID
  19. </select>
  20. <!-- 민간센터 정보 -->
  21. <select id="getMocInfo" resultType="com.tsi.monitoring.vo.CenterVo">
  22. SELECT A.CENTERID CENTER_ID,
  23. CENTERINFO CENTER_INFO,
  24. IPADDRESS IP_ADDRESS,
  25. NVL(COMMPORT, 0) COMM_PORT
  26. FROM CENTER_MOCT A
  27. WHERE CENTERFLAG != 'M'
  28. ORDER BY CENTER_ID
  29. </select>
  30. <!-- 신호연계센터 정보 -->
  31. <select id="getSigRegionInfo" resultType="com.tsi.monitoring.vo.CenterVo">
  32. SELECT A.REGION_CD AS CENTER_ID,
  33. A.REGION_NM AS CENTER_INFO,
  34. A.IP_ADDRESS AS IP_ADDRESS,
  35. NVL(A.COMM_PORT, 0) AS COMM_PORT
  36. FROM TB_REGION_CENTER@SIGDB A
  37. ORDER BY CENTER_ID
  38. </select>
  39. <!-- 신호연계 교차로 정보 -->
  40. <select id="getSigIntInfo" resultType="com.tsi.monitoring.vo.CenterVo">
  41. SELECT A.REGION_CD AS CENTER_ID,
  42. TO_CHAR(A.INT_NO) AS INT_NO,
  43. A.INT_NM AS INT_NM
  44. FROM TB_INT@SIGDB A
  45. ORDER BY CENTER_ID, INT_NM
  46. </select>
  47. <select id="getLocalCenterLinkInfo" resultType="com.tsi.monitoring.vo.LocalCenterLinkVo">
  48. <![CDATA[
  49. WITH RCV AS (
  50. SELECT
  51. MAX(LOGDATE) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS RLOGDATE,
  52. MAX(DATACNT) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS RDATACNT,
  53. MAX(INFOTYPE) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS RINFOTYPE,
  54. CENTERID
  55. FROM UTIADMIN.center_receive
  56. WHERE LOGDATE >= TRUNC(SYSDATE - 2)
  57. AND INFOTYPE = 'R1'
  58. GROUP BY CENTERID
  59. ),
  60. SND AS (
  61. SELECT
  62. MAX(LOGDATE) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS SLOGDATE,
  63. MAX(DATACNT) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS SDATACNT,
  64. MAX(INFOTYPE) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS SINFOTYPE,
  65. CENTERID
  66. FROM UTIADMIN.center_send
  67. WHERE LOGDATE >= TRUNC(SYSDATE - 2)
  68. AND INFOTYPE = 'R1'
  69. GROUP BY CENTERID
  70. ),
  71. SND_MOCT AS (
  72. SELECT
  73. MAX(LOGDATE) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS MLOGDATE,
  74. MAX(DATACNT) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS MDATACNT,
  75. MAX(INFOTYPE) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS MINFOTYPE,
  76. CENTERID
  77. FROM UTIADMIN.center_send
  78. WHERE LOGDATE >= TRUNC(SYSDATE - 2)
  79. AND INFOTYPE = 'M1'
  80. GROUP BY CENTERID
  81. ),
  82. SIG_CENTER AS (
  83. SELECT REGION_CD,
  84. REGION_NM,
  85. REG_DATE,
  86. ERR_TIME_GAP
  87. FROM TB_REGION_CENTER@SIGDB
  88. ),
  89. CENTER_CTE AS (
  90. SELECT * FROM CENTER WHERE CENTERFLAG != 'M'
  91. ),
  92. MOCT_CENTER AS (
  93. SELECT CENTERID, MOCTYN FROM CENTER_MOCT WHERE CENTERFLAG != 'M'
  94. )
  95. SELECT DECODE(C.CENTERID, NULL, 'N', 'Y') AS IS_CENTER,
  96. DECODE(SC.REGION_CD, NULL, 'N', 'Y') AS IS_SIG,
  97. NVL(C.CENTERID, SC.REGION_CD) AS CENTER_ID,
  98. NVL(C.CENTERINFO, SC.REGION_NM) AS CENTER_NM,
  99. C.IPADDRESS AS IP_ADDRESS,
  100. NVL(C.COMMPORT, 0) AS COMM_PORT,
  101. TO_CHAR(R.RLOGDATE, 'YYYY-MM-DD HH24:MI:SS') AS R_LOG_DATE,
  102. CASE WHEN C.CENTERID IS NULL THEN NULL WHEN R.RLOGDATE IS NULL OR R.RLOGDATE < SYSDATE - (5/(24*60)) THEN 1 ELSE 0 END AS R_COMM_STATE,
  103. R.RDATACNT AS R_DATA_CNT,
  104. R.RINFOTYPE AS R_INFO_TYPE,
  105. C.RCVYN AS R_YN,
  106. DECODE(R.RINFOTYPE, 'R1','소통정보','E1','돌발정보','-') AS R_INFO_TYPE_DESC,
  107. TO_CHAR(S.SLOGDATE, 'YYYY-MM-DD HH24:MI:SS') AS S_LOG_DATE,
  108. CASE WHEN C.CENTERID IS NULL THEN NULL WHEN S.SLOGDATE IS NULL OR S.SLOGDATE < SYSDATE - (5/(24*60)) THEN 1 ELSE 0 END AS S_COMM_STATE,
  109. S.SDATACNT AS S_DATA_CNT,
  110. S.SINFOTYPE AS S_INFO_TYPE,
  111. C.TRAFFICYN AS S_YN,
  112. DECODE(S.SINFOTYPE, 'R1','소통정보','E1','돌발정보','-') AS S_INFO_TYPE_DESC,
  113. TO_CHAR(M.MLOGDATE, 'YYYY-MM-DD HH24:MI:SS') AS M_LOG_DATE,
  114. CASE WHEN C.CENTERID IS NULL THEN NULL WHEN M.MLOGDATE IS NULL OR M.MLOGDATE < SYSDATE - (5/(24*60)) THEN 1 ELSE 0 END AS M_COMM_STATE,
  115. M.MDATACNT AS M_DATA_CNT,
  116. M.MINFOTYPE AS M_INFO_TYPE,
  117. MC.MOCTYN AS M_YN,
  118. '소통정보' AS M_INFO_TYPE_DESC,
  119. TO_CHAR(SC.REG_DATE, 'YYYY-MM-DD HH24:MI:SS') AS SL_LOG_DATE,
  120. CASE WHEN SC.REGION_CD IS NULL THEN NULL WHEN SC.REG_DATE IS NULL OR SC.REG_DATE < SYSDATE - SC.ERR_TIME_GAP/(24*60*60) THEN 1 ELSE 0 END SL_COMM_STATE
  121. FROM CENTER_CTE C
  122. LEFT OUTER JOIN MOCT_CENTER MC ON C.CENTERID = MC.CENTERID
  123. LEFT JOIN RCV R ON C.CENTERID = R.CENTERID
  124. LEFT JOIN SND S ON C.CENTERID = S.CENTERID
  125. LEFT JOIN SND_MOCT M ON C.CENTERID = M.CENTERID
  126. FULL OUTER JOIN SIG_CENTER SC ON C.CENTERID = SC.REGION_CD
  127. ORDER BY CENTER_ID
  128. ]]>
  129. </select>
  130. <!-- <select id="getLocalCenterLinkInfo" resultType="com.tsi.monitoring.vo.LocalCenterLinkVo">-->
  131. <!-- <![CDATA[-->
  132. <!-- WITH RCV AS (-->
  133. <!-- SELECT FROMCENTERID AS CENTERID,-->
  134. <!-- MAX(LOGDATE) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS RLOGDATE,-->
  135. <!-- MAX(DATACNT) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS RDATACNT,-->
  136. <!-- MAX(INFOKIND) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS RINFOTYPE-->
  137. <!-- FROM RCV_LOG-->
  138. <!-- GROUP BY FROMCENTERID-->
  139. <!-- ),-->
  140. <!-- SND AS (-->
  141. <!-- SELECT TOCENTERID AS CENTERID,-->
  142. <!-- MAX(LOGDATE) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS SLOGDATE,-->
  143. <!-- MAX(DATACNT) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS SDATACNT,-->
  144. <!-- MAX(INFOKIND) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS SINFOTYPE-->
  145. <!-- FROM SND_LOG-->
  146. <!-- GROUP BY TOCENTERID-->
  147. <!-- ),-->
  148. <!-- SND_MOCT AS (-->
  149. <!-- SELECT TOCENTERID AS CENTERID,-->
  150. <!-- MAX(LOGDATE) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS MLOGDATE,-->
  151. <!-- MAX(DATACNT) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS MDATACNT,-->
  152. <!-- MAX(INFOKIND) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS MINFOTYPE-->
  153. <!-- FROM SND_LOG_MOCT-->
  154. <!-- GROUP BY TOCENTERID-->
  155. <!-- ),-->
  156. <!-- SIG_CENTER AS (-->
  157. <!-- SELECT REGION_CD,-->
  158. <!-- REGION_NM,-->
  159. <!-- REG_DATE,-->
  160. <!-- ERR_TIME_GAP-->
  161. <!-- FROM TB_REGION_CENTER@SIGDB-->
  162. <!-- ),-->
  163. <!-- CENTER_CTE AS (-->
  164. <!-- SELECT * FROM CENTER WHERE CENTERFLAG != 'M'-->
  165. <!-- ),-->
  166. <!-- MOCT_CENTER AS (-->
  167. <!-- SELECT CENTERID, MOCTYN FROM CENTER_MOCT WHERE CENTERFLAG != 'M'-->
  168. <!-- )-->
  169. <!-- SELECT DECODE(C.CENTERID, NULL, 'N', 'Y') AS IS_CENTER,-->
  170. <!-- DECODE(SC.REGION_CD, NULL, 'N', 'Y') AS IS_SIG,-->
  171. <!-- NVL(C.CENTERID, SC.REGION_CD) AS CENTER_ID,-->
  172. <!-- NVL(C.CENTERINFO, SC.REGION_NM) AS CENTER_NM,-->
  173. <!-- C.IPADDRESS AS IP_ADDRESS,-->
  174. <!-- NVL(C.COMMPORT, 0) AS COMM_PORT,-->
  175. <!-- TO_CHAR(R.RLOGDATE, 'YYYY-MM-DD HH24:MI:SS') AS R_LOG_DATE,-->
  176. <!-- CASE WHEN C.CENTERID IS NULL THEN NULL WHEN R.RLOGDATE IS NULL OR R.RLOGDATE < SYSDATE - (5/(24*60)) THEN 1 ELSE 0 END AS R_COMM_STATE,-->
  177. <!-- R.RDATACNT AS R_DATA_CNT,-->
  178. <!-- R.RINFOTYPE AS R_INFO_TYPE,-->
  179. <!-- C.RCVYN AS R_YN,-->
  180. <!-- DECODE(R.RINFOTYPE, 'T','소통정보','I','돌발정보','C','통제정보','-') AS R_INFO_TYPE_DESC,-->
  181. <!-- TO_CHAR(S.SLOGDATE, 'YYYY-MM-DD HH24:MI:SS') AS S_LOG_DATE,-->
  182. <!-- CASE WHEN C.CENTERID IS NULL THEN NULL WHEN S.SLOGDATE IS NULL OR S.SLOGDATE < SYSDATE - (5/(24*60)) THEN 1 ELSE 0 END AS S_COMM_STATE,-->
  183. <!-- S.SDATACNT AS S_DATA_CNT,-->
  184. <!-- S.SINFOTYPE AS S_INFO_TYPE,-->
  185. <!-- C.TRAFFICYN AS S_YN,-->
  186. <!-- DECODE(S.SINFOTYPE, 'T','소통정보','I','돌발정보','C','통제정보','-') AS S_INFO_TYPE_DESC,-->
  187. <!-- TO_CHAR(M.MLOGDATE, 'YYYY-MM-DD HH24:MI:SS') AS M_LOG_DATE,-->
  188. <!-- CASE WHEN C.CENTERID IS NULL THEN NULL WHEN M.MLOGDATE IS NULL OR M.MLOGDATE < SYSDATE - (5/(24*60)) THEN 1 ELSE 0 END AS M_COMM_STATE,-->
  189. <!-- M.MDATACNT AS M_DATA_CNT,-->
  190. <!-- M.MINFOTYPE AS M_INFO_TYPE,-->
  191. <!-- MC.MOCTYN AS M_YN,-->
  192. <!-- DECODE(M.MINFOTYPE, 'T','소통정보','I','돌발정보','C','통제정보','-') AS M_INFO_TYPE_DESC,-->
  193. <!-- TO_CHAR(SC.REG_DATE, 'YYYY-MM-DD HH24:MI:SS') AS SL_LOG_DATE,-->
  194. <!-- CASE WHEN SC.REGION_CD IS NULL THEN NULL WHEN SC.REG_DATE IS NULL OR SC.REG_DATE < SYSDATE - SC.ERR_TIME_GAP/(24*60*60) THEN 1 ELSE 0 END SL_COMM_STATE-->
  195. <!-- FROM CENTER_CTE C-->
  196. <!-- LEFT OUTER JOIN MOCT_CENTER MC ON C.CENTERID = MC.CENTERID-->
  197. <!-- LEFT JOIN RCV R ON C.CENTERID = R.CENTERID-->
  198. <!-- LEFT JOIN SND S ON C.CENTERID = S.CENTERID-->
  199. <!-- LEFT JOIN SND_MOCT M ON C.CENTERID = M.CENTERID-->
  200. <!-- FULL OUTER JOIN SIG_CENTER SC ON C.CENTERID = SC.REGION_CD-->
  201. <!-- ORDER BY CENTER_ID-->
  202. <!-- ]]>-->
  203. <!-- </select>-->
  204. <!-- 센터 민간 송수신 정보 조회 -->
  205. <select id="getMocSendRecvLog" resultType="com.tsi.monitoring.vo.LogVo">
  206. SELECT C.CENTERID AS CENTER_ID,
  207. TO_CHAR(RLOGDATE, 'YYYY-MM-DD HH24:MI:SS') R_LOG_DATE,
  208. CASE WHEN RLOGDATE IS NULL
  209. OR RLOGDATE <![CDATA[<]]> SYSDATE - 5/(24*60)
  210. THEN 1
  211. ELSE 0
  212. END R_COMM_STATE,
  213. NVL(RDATACNT, 0) R_DATA_CNT,
  214. RINFOTYPE AS R_INFO_TYPE,
  215. DECODE(RINFOTYPE, 'T', '소통정보', 'I', '돌발정보', 'C', '통제정보', '-') AS R_INFO_TYPE_DESC,
  216. TO_CHAR(SLOGDATE, 'YYYY-MM-DD HH24:MI:SS') S_LOG_DATE,
  217. CASE WHEN SLOGDATE IS NULL
  218. OR SLOGDATE <![CDATA[<]]> SYSDATE - 5/(24*60)
  219. THEN 1
  220. ELSE 0
  221. END S_COMM_STATE,
  222. NVL(SDATACNT, 0) S_DATA_CNT,
  223. SINFOTYPE AS S_INFO_TYPE,
  224. DECODE(SINFOTYPE, 'T', '소통정보', 'I', '돌발정보', 'C', '통제정보', '-') AS S_INFO_TYPE_DESC,
  225. TO_CHAR(MLOGDATE, 'YYYY-MM-DD HH24:MI:SS') M_LOG_DATE,
  226. CASE WHEN MLOGDATE IS NULL
  227. OR MLOGDATE <![CDATA[<]]> SYSDATE - 5/(24*60)
  228. THEN 1
  229. ELSE 0
  230. END M_COMM_STATE,
  231. NVL(MDATACNT, 0) M_DATA_CNT,
  232. MINFOTYPE AS M_INFO_TYPE,
  233. DECODE(MINFOTYPE, 'T', '소통정보', 'I', '돌발정보', 'C', '통제정보', '-') AS M_INFO_TYPE_DESC
  234. FROM CENTER C,
  235. (
  236. SELECT LOGDATE RLOGDATE, FROMCENTERID CENTERID, DATACNT RDATACNT, INFOKIND RINFOTYPE
  237. FROM (
  238. SELECT LOGDATE, FROMCENTERID, DATACNT, INFOKIND,
  239. ROW_NUMBER() OVER(PARTITION BY FROMCENTERID ORDER BY LOGDATE DESC) RRN
  240. FROM RCV_LOG A1
  241. )
  242. WHERE RRN = 1
  243. ) A,
  244. (
  245. SELECT LOGDATE SLOGDATE, TOCENTERID CENTERID, DATACNT SDATACNT, INFOKIND SINFOTYPE
  246. FROM (
  247. SELECT TOCENTERID, LOGDATE, DATACNT, INFOKIND,
  248. ROW_NUMBER() OVER(PARTITION BY TOCENTERID ORDER BY LOGDATE DESC) SRN
  249. FROM SND_LOG
  250. )
  251. WHERE SRN = 1
  252. ) B,
  253. (
  254. SELECT LOGDATE MLOGDATE, TOCENTERID CENTERID, DATACNT MDATACNT, INFOKIND MINFOTYPE
  255. FROM (
  256. SELECT TOCENTERID, LOGDATE, DATACNT, INFOKIND,
  257. ROW_NUMBER() OVER(PARTITION BY TOCENTERID ORDER BY LOGDATE DESC) MRN
  258. FROM SND_LOG_MOCT
  259. )
  260. WHERE MRN = 1
  261. ) D
  262. WHERE C.CENTERID = A.CENTERID(+)
  263. AND C.CENTERID = B.CENTERID(+)
  264. AND C.CENTERID = D.CENTERID(+)
  265. AND C.CENTERFLAG != 'M'
  266. </select>
  267. <!-- 신호연계 상태정보 -->
  268. <select id="getSigStatusInfo" resultType="com.tsi.monitoring.vo.StatusVo">
  269. SELECT A.REGION_CD AS CENTER_ID,
  270. DECODE(A.REG_DATE, NULL, '1', NVL(A.COMM_STATE, '1')) AS RUN_STATE,
  271. A.ERR_TIME_GAP AS ERR_TIME_GAP,
  272. DECODE(A.REG_DATE, NULL, 9000, ROUND((SYSDATE-A.REG_DATE)*24*60*60)) AS REG_TIME_GAP,
  273. TO_CHAR(A.REG_DATE, 'YYYY-MM-DD HH24:MI:SS') AS LAST_REG_DATE
  274. FROM TB_REGION_CENTER@SIGDB A
  275. ORDER BY CENTER_ID
  276. </select>
  277. <!-- 신호연계 교차로 상태 정보 조회 -->
  278. <select id="getSigIntStatusInfo" resultType="com.tsi.monitoring.vo.IntStatusVo">
  279. SELECT A.REGION_CD AS CENTER_ID,
  280. TO_CHAR(A.INT_NO) AS INT_NO,
  281. TO_CHAR(A.COLLCT_DTIME, 'YYYY-MM-DD HH24:MI:SS') AS COLL_DATE,
  282. NVL(A.COMM_ON_OFF_FLAG, '1') AS COMM_STAT,
  283. A.CONTRLR_OPER_MODE_CD AS OPER_MODE
  284. FROM TB_INT_STATUS@SIGDB A
  285. </select>
  286. <!-- 센터/민간 로그 정보조회 -->
  287. <select id="getMogLogInfo" resultType="com.tsi.monitoring.vo.MocLogInfoVo" parameterType="java.util.HashMap">
  288. SELECT TO_CHAR(LOGDATE, 'YYYY-MM-DD HH24:MI:SS') AS LOG_DATE,
  289. INFOKIND AS TYPE,
  290. FROMCENTERID AS CENTER_ID,
  291. DATACNT AS DATA_CNT,
  292. DUPKEY AS DUP_KEY,
  293. 'R' AS RS
  294. FROM RCV_LOG
  295. WHERE FROMCENTERID = #{centerId}
  296. AND LOGDATE >= TRUNC(SYSDATE)
  297. UNION
  298. SELECT TO_CHAR(LOGDATE, 'YYYY-MM-DD HH24:MI:SS') AS LOG_DATE,
  299. INFOKIND AS TYPE,
  300. TOCENTERID AS CENTER_ID,
  301. DATACNT AS DATA_CNT,
  302. '' AS DUP_KEY,
  303. 'S' AS RS
  304. FROM SND_LOG
  305. WHERE TOCENTERID = #{centerId}
  306. AND LOGDATE >= TRUNC(SYSDATE)
  307. UNION
  308. SELECT TO_CHAR(LOGDATE, 'YYYY-MM-DD HH24:MI:SS') AS LOG_DATE,
  309. INFOKIND AS TYPE,
  310. TOCENTERID AS CENTER_ID,
  311. DATACNT AS DATA_CNT,
  312. '' AS DUP_KEY,
  313. 'M' AS RS
  314. FROM SND_LOG_MOCT
  315. WHERE TOCENTERID = #{centerId}
  316. AND LOGDATE >= TRUNC(SYSDATE)
  317. </select>
  318. <select id="getCenterPreferences" resultType="com.tsi.monitoring.vo.CenterPreferencesVo">
  319. SELECT CENTERID AS CENTER_ID,
  320. CENTERINFO AS CENTER_INFO,
  321. TRAFFICYN AS TRAFFIC_YN,
  322. INCIDENTYN AS INCIDENT_YN,
  323. CONTROLYN AS CONTROL_YN
  324. FROM CENTER
  325. WHERE CENTERFLAG = 'L'
  326. ORDER BY CENTERID
  327. </select>
  328. <!-- SELECT DECODE(LOG.LOGDATE, NULL, '-', TO_CHAR(LOG.LOGDATE, 'YYYY-MM-DD HH24:MI:SS')) AS LOG_DATE,-->
  329. <!-- DECODE(LOG.INFOKIND, 'T', '소통정보', 'I', '돌발정보', 'C', '통제정보', '-') AS INFO_KIND,-->
  330. <!-- LOG.DATACNT DATA_CNT,-->
  331. <!-- FROM_C.CENTERINFO AS FROM_NM,-->
  332. <!-- TO_C.CENTERINFO AS TO_NM-->
  333. <!-- FROM RCV_LOG LOG, CENTER FROM_C, CENTER TO_C-->
  334. <!-- WHERE LOG.FROMCENTERID = FROM_C.CENTERID-->
  335. <!-- AND LOG.TOCENTERID = TO_C.CENTERID-->
  336. <!-- AND LOG.FROMCENTERID = #{centerId}-->
  337. <!-- AND LOG.LOGDATE >= TRUNC(SYSDATE)-->
  338. <!-- ORDER BY LOG_DATE DESC-->
  339. <select id="getRcvHistory" resultType="com.tsi.monitoring.vo.HistoryVo" parameterType="java.util.HashMap">
  340. <![CDATA[
  341. WITH DATE_5M AS (
  342. SELECT TRUNC(SYSDATE) + (LEVEL - 1) * (5/24/60) AS LOG_DATE_5M
  343. FROM DUAL
  344. CONNECT BY LEVEL <= 288
  345. ),
  346. rcv AS (
  347. SELECT LOG.LOGDATE AS LOG_DATE,
  348. DECODE(LOG.INFOTYPE, 'R1', '소통정보', 'E1', '돌발정보', '-') AS INFO_KIND,
  349. LOG.DATACNT DATA_CNT,
  350. FROM_C.CENTERINFO AS FROM_NM,
  351. TO_C.CENTERINFO AS TO_NM
  352. FROM UTIADMIN.CENTER_RECEIVE LOG, (SELECT CENTERINFO FROM CENTER WHERE CENTERID = 'L00') TO_C, CENTER FROM_C
  353. WHERE LOG.CENTERID = #{centerId}
  354. AND LOG.CENTERID = FROM_C.CENTERID
  355. AND LOG.LOGDATE > TRUNC(SYSDATE)
  356. )
  357. SELECT TO_CHAR(t.LOG_DATE_5M, 'YYYY-MM-DD HH24:MI:SS') AS LOG_DATE,
  358. r.INFO_KIND,
  359. NVL(SUM(r.DATA_CNT), 0) AS DATA_CNT,
  360. MAX(r.FROM_NM) AS FROM_NM,
  361. MAX(r.TO_NM) AS TO_NM
  362. FROM DATE_5M t
  363. JOIN rcv r
  364. ON r.LOG_DATE >= t.LOG_DATE_5M
  365. AND r.LOG_DATE < t.LOG_DATE_5M + (5/24/60)
  366. GROUP BY t.LOG_DATE_5M, r.INFO_KIND
  367. ORDER BY t.LOG_DATE_5M, r.INFO_KIND
  368. ]]>
  369. </select>
  370. <!-- <select id="getSendHistory" resultType="com.tsi.monitoring.vo.HistoryVo" parameterType="java.util.HashMap">-->
  371. <!-- SELECT DECODE(LOG.LOGDATE, NULL, '-', TO_CHAR(LOG.LOGDATE, 'YYYY-MM-DD HH24:MI:SS')) AS LOG_DATE,-->
  372. <!-- DECODE(LOG.INFOKIND, 'T', '소통정보', 'I', '돌발정보', 'C', '통제정보', '-') AS INFO_KIND,-->
  373. <!-- LOG.DATACNT DATA_CNT,-->
  374. <!-- FROM_C.CENTERINFO AS FROM_NM,-->
  375. <!-- TO_C.CENTERINFO AS TO_NM-->
  376. <!-- FROM SND_LOG LOG, CENTER FROM_C, CENTER TO_C-->
  377. <!-- WHERE LOG.FROMCENTERID = FROM_C.CENTERID-->
  378. <!-- AND LOG.TOCENTERID = TO_C.CENTERID-->
  379. <!-- AND LOG.TOCENTERID = #{centerId}-->
  380. <!-- AND LOG.LOGDATE >= TRUNC(SYSDATE)-->
  381. <!-- ORDER BY LOG_DATE DESC-->
  382. <!-- </select>-->
  383. <select id="getSendHistory" resultType="com.tsi.monitoring.vo.HistoryVo" parameterType="java.util.HashMap">
  384. <![CDATA[
  385. WITH DATE_5M AS (
  386. SELECT TRUNC(SYSDATE) + (LEVEL - 1) * (5/24/60) AS LOG_DATE_5M
  387. FROM DUAL
  388. CONNECT BY LEVEL <= 288
  389. ),
  390. rcv AS (
  391. SELECT LOG.LOGDATE AS LOG_DATE,
  392. DECODE(LOG.INFOTYPE, 'R1', '소통정보', 'E1', '돌발정보', '-') AS INFO_KIND,
  393. LOG.DATACNT DATA_CNT,
  394. FROM_C.CENTERINFO AS FROM_NM,
  395. TO_C.CENTERINFO AS TO_NM
  396. FROM UTIADMIN.CENTER_SEND LOG, (SELECT CENTERINFO FROM CENTER WHERE CENTERID = 'L00') FROM_C, CENTER TO_C
  397. WHERE LOG.CENTERID = 'L02'
  398. AND LOG.CENTERID = TO_C.CENTERID
  399. AND LOG.LOGDATE > TRUNC(SYSDATE)
  400. AND LOG.INFOTYPE <> 'M1'
  401. )
  402. SELECT TO_CHAR(t.LOG_DATE_5M, 'YYYY-MM-DD HH24:MI:SS') AS LOG_DATE,
  403. r.INFO_KIND,
  404. NVL(SUM(r.DATA_CNT), 0) AS DATA_CNT,
  405. MAX(r.FROM_NM) AS FROM_NM,
  406. MAX(r.TO_NM) AS TO_NM
  407. FROM DATE_5M t
  408. JOIN rcv r
  409. ON r.LOG_DATE >= t.LOG_DATE_5M
  410. AND r.LOG_DATE < t.LOG_DATE_5M + (5/24/60)
  411. GROUP BY t.LOG_DATE_5M, r.INFO_KIND
  412. ORDER BY t.LOG_DATE_5M, r.INFO_KIND
  413. ]]>
  414. </select>
  415. <!-- SELECT DECODE(LOG.LOGDATE, NULL, '-', TO_CHAR(LOG.LOGDATE, 'YYYY-MM-DD HH24:MI:SS')) AS LOG_DATE,-->
  416. <!-- DECODE(LOG.INFOKIND, 'T', '소통정보', 'I', '돌발정보', 'C', '통제정보', '-') AS INFO_KIND,-->
  417. <!-- LOG.DATACNT DATA_CNT,-->
  418. <!-- FROM_C.CENTERINFO AS FROM_NM,-->
  419. <!-- TO_C.CENTERINFO AS TO_NM-->
  420. <!-- FROM SND_LOG_MOCT LOG, CENTER FROM_C, CENTER TO_C-->
  421. <!-- WHERE LOG.FROMCENTERID = FROM_C.CENTERID-->
  422. <!-- AND LOG.TOCENTERID = TO_C.CENTERID-->
  423. <!-- AND LOG.TOCENTERID = #{centerId}-->
  424. <!-- AND LOG.LOGDATE >= TRUNC(SYSDATE)-->
  425. <!-- ORDER BY LOG_DATE DESC-->
  426. <select id="getMoctHistory" resultType="com.tsi.monitoring.vo.HistoryVo" parameterType="java.util.HashMap">
  427. <![CDATA[
  428. WITH DATE_5M AS (
  429. SELECT TRUNC(SYSDATE) + (LEVEL - 1) * (5/24/60) AS LOG_DATE_5M
  430. FROM DUAL
  431. CONNECT BY LEVEL <= 288
  432. ),
  433. rcv AS (
  434. SELECT LOG.LOGDATE AS LOG_DATE,
  435. '소통정보' AS INFO_KIND,
  436. LOG.DATACNT DATA_CNT,
  437. FROM_C.CENTERINFO AS FROM_NM,
  438. TO_C.CENTERINFO AS TO_NM
  439. FROM UTIADMIN.CENTER_SEND LOG, (SELECT CENTERINFO FROM CENTER WHERE CENTERID = 'L00') FROM_C, CENTER TO_C
  440. WHERE LOG.CENTERID = 'L02'
  441. AND LOG.CENTERID = TO_C.CENTERID
  442. AND LOG.LOGDATE > TRUNC(SYSDATE)
  443. AND LOG.INFOTYPE = 'M1'
  444. )
  445. SELECT TO_CHAR(t.LOG_DATE_5M, 'YYYY-MM-DD HH24:MI:SS') AS LOG_DATE,
  446. r.INFO_KIND,
  447. NVL(SUM(r.DATA_CNT), 0) AS DATA_CNT,
  448. MAX(r.FROM_NM) AS FROM_NM,
  449. MAX(r.TO_NM) AS TO_NM
  450. FROM DATE_5M t
  451. JOIN rcv r
  452. ON r.LOG_DATE >= t.LOG_DATE_5M
  453. AND r.LOG_DATE < t.LOG_DATE_5M + (5/24/60)
  454. GROUP BY t.LOG_DATE_5M, r.INFO_KIND
  455. ORDER BY t.LOG_DATE_5M, r.INFO_KIND
  456. ]]>
  457. </select>
  458. <select id="getIntStatusHistory" resultType="com.tsi.monitoring.vo.IntStatusVo" parameterType="java.util.HashMap">
  459. SELECT TIS.REGION_CD AS CENTER_ID,
  460. TIS.INT_NO,
  461. TI.INT_NM,
  462. TIS.COLLCT_DTIME AS COLL_DATE,
  463. TIS.CONTRLR_OPER_MODE_CD AS OPER_MODE,
  464. DECODE(TIS.CONTRLR_OPER_MODE_CD,
  465. '0', 'SCU모드'
  466. , '1', '비감응 OFFLINE'
  467. , '2', '감응 OFFLINE'
  468. , '4', '감응 ONLINE'
  469. , '5', 'ONLINE'
  470. , TIS.CONTRLR_OPER_MODE_CD || '_Unknown'
  471. ) AS OPER_MODE_DESC,
  472. TIS.COMM_ON_OFF_FLAG AS COMM_STAT
  473. FROM TB_INT_STATUS@SIGDB TIS
  474. JOIN TB_INT@SIGDB TI
  475. ON TIS.REGION_CD = TI.REGION_CD
  476. AND TIS.INT_NO = TI.INT_NO
  477. AND TIS.REGION_CD = #{centerId}
  478. ORDER BY TIS.INT_NO
  479. </select>
  480. <select id="getRcvStatistics" parameterType="java.util.HashMap" resultType="com.tsi.monitoring.vo.StatisticsVo">
  481. <![CDATA[
  482. WITH HOURS AS (
  483. SELECT TO_CHAR(LEVEL - 1, 'FM00') AS HH
  484. FROM DUAL
  485. CONNECT BY LEVEL <= 24
  486. ),
  487. RAW_DATA AS (
  488. SELECT TO_CHAR(LOGDATE, 'HH24') AS HH,
  489. LPAD(FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5) * 5, 2, '0') AS MIN_GROUP,
  490. SUM(DATACNT) AS SUM_DATACNT
  491. FROM RCV_LOG
  492. WHERE FROMCENTERID = #{centerId}
  493. AND LOGDATE >= TRUNC(SYSDATE)
  494. AND LOGDATE < TRUNC(SYSDATE + 1)
  495. AND INFOKIND = #{infoKind}
  496. GROUP BY TO_CHAR(LOGDATE, 'HH24'), FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5)
  497. ),
  498. PIVOTED AS (
  499. SELECT * FROM RAW_DATA
  500. PIVOT (
  501. SUM(SUM_DATACNT)
  502. FOR MIN_GROUP IN (
  503. '00' AS M00, '05' AS M05, '10' AS M10, '15' AS M15,
  504. '20' AS M20, '25' AS M25, '30' AS M30, '35' AS M35,
  505. '40' AS M40, '45' AS M45, '50' AS M50, '55' AS M55
  506. )
  507. )
  508. )
  509. SELECT H.HH,
  510. NVL(P.M00, 0) AS M00,
  511. NVL(P.M05, 0) AS M05,
  512. NVL(P.M10, 0) AS M10,
  513. NVL(P.M15, 0) AS M15,
  514. NVL(P.M20, 0) AS M20,
  515. NVL(P.M25, 0) AS M25,
  516. NVL(P.M30, 0) AS M30,
  517. NVL(P.M35, 0) AS M35,
  518. NVL(P.M40, 0) AS M40,
  519. NVL(P.M45, 0) AS M45,
  520. NVL(P.M50, 0) AS M50,
  521. NVL(P.M55, 0) AS M55,
  522. NVL(P.M00, 0) + NVL(P.M05, 0) + NVL(P.M10, 0) + NVL(P.M15, 0) + NVL(P.M20, 0) + NVL(P.M25, 0) +
  523. NVL(P.M30, 0) + NVL(P.M35, 0) + NVL(P.M40, 0) + NVL(P.M45, 0) + NVL(P.M50, 0) + NVL(P.M55, 0) AS TOTAL
  524. FROM HOURS H
  525. LEFT JOIN PIVOTED P ON H.HH = P.HH
  526. ORDER BY H.HH
  527. ]]>
  528. </select>
  529. <select id="getSndStatistics" parameterType="java.util.HashMap" resultType="com.tsi.monitoring.vo.StatisticsVo">
  530. <![CDATA[
  531. WITH HOURS AS (
  532. SELECT TO_CHAR(LEVEL - 1, 'FM00') AS HH
  533. FROM DUAL
  534. CONNECT BY LEVEL <= 24
  535. ),
  536. RAW_DATA AS (
  537. SELECT TO_CHAR(LOGDATE, 'HH24') AS HH,
  538. LPAD(FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5) * 5, 2, '0') AS MIN_GROUP,
  539. SUM(DATACNT) AS SUM_DATACNT
  540. FROM SND_LOG
  541. WHERE TOCENTERID = #{centerId}
  542. AND LOGDATE >= TRUNC(SYSDATE)
  543. AND LOGDATE < TRUNC(SYSDATE + 1)
  544. AND INFOKIND = #{infoKind}
  545. GROUP BY TO_CHAR(LOGDATE, 'HH24'), FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5)
  546. ),
  547. PIVOTED AS (
  548. SELECT * FROM RAW_DATA
  549. PIVOT (
  550. SUM(SUM_DATACNT)
  551. FOR MIN_GROUP IN (
  552. '00' AS M00, '05' AS M05, '10' AS M10, '15' AS M15,
  553. '20' AS M20, '25' AS M25, '30' AS M30, '35' AS M35,
  554. '40' AS M40, '45' AS M45, '50' AS M50, '55' AS M55
  555. )
  556. )
  557. )
  558. SELECT H.HH,
  559. NVL(P.M00, 0) AS M00,
  560. NVL(P.M05, 0) AS M05,
  561. NVL(P.M10, 0) AS M10,
  562. NVL(P.M15, 0) AS M15,
  563. NVL(P.M20, 0) AS M20,
  564. NVL(P.M25, 0) AS M25,
  565. NVL(P.M30, 0) AS M30,
  566. NVL(P.M35, 0) AS M35,
  567. NVL(P.M40, 0) AS M40,
  568. NVL(P.M45, 0) AS M45,
  569. NVL(P.M50, 0) AS M50,
  570. NVL(P.M55, 0) AS M55,
  571. NVL(P.M00, 0) + NVL(P.M05, 0) + NVL(P.M10, 0) + NVL(P.M15, 0) + NVL(P.M20, 0) + NVL(P.M25, 0) +
  572. NVL(P.M30, 0) + NVL(P.M35, 0) + NVL(P.M40, 0) + NVL(P.M45, 0) + NVL(P.M50, 0) + NVL(P.M55, 0) AS TOTAL
  573. FROM HOURS H
  574. LEFT JOIN PIVOTED P ON H.HH = P.HH
  575. ORDER BY H.HH
  576. ]]>
  577. </select>
  578. <select id="getSndMoctStatistics" parameterType="java.lang.String" resultType="com.tsi.monitoring.vo.StatisticsVo">
  579. <![CDATA[
  580. WITH HOURS AS (
  581. SELECT TO_CHAR(LEVEL - 1, 'FM00') AS HH
  582. FROM DUAL
  583. CONNECT BY LEVEL <= 24
  584. ),
  585. RAW_DATA AS (
  586. SELECT TO_CHAR(LOGDATE, 'HH24') AS HH,
  587. LPAD(FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5) * 5, 2, '0') AS MIN_GROUP,
  588. SUM(DATACNT) AS SUM_DATACNT
  589. FROM SND_LOG_MOCT
  590. WHERE TOCENTERID = #{centerId}
  591. AND LOGDATE >= TRUNC(SYSDATE)
  592. AND LOGDATE < TRUNC(SYSDATE + 1)
  593. GROUP BY TO_CHAR(LOGDATE, 'HH24'), FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5)
  594. ),
  595. PIVOTED AS (
  596. SELECT * FROM RAW_DATA
  597. PIVOT (
  598. SUM(SUM_DATACNT)
  599. FOR MIN_GROUP IN (
  600. '00' AS M00, '05' AS M05, '10' AS M10, '15' AS M15,
  601. '20' AS M20, '25' AS M25, '30' AS M30, '35' AS M35,
  602. '40' AS M40, '45' AS M45, '50' AS M50, '55' AS M55
  603. )
  604. )
  605. )
  606. SELECT H.HH,
  607. NVL(P.M00, 0) AS M00,
  608. NVL(P.M05, 0) AS M05,
  609. NVL(P.M10, 0) AS M10,
  610. NVL(P.M15, 0) AS M15,
  611. NVL(P.M20, 0) AS M20,
  612. NVL(P.M25, 0) AS M25,
  613. NVL(P.M30, 0) AS M30,
  614. NVL(P.M35, 0) AS M35,
  615. NVL(P.M40, 0) AS M40,
  616. NVL(P.M45, 0) AS M45,
  617. NVL(P.M50, 0) AS M50,
  618. NVL(P.M55, 0) AS M55,
  619. NVL(P.M00, 0) + NVL(P.M05, 0) + NVL(P.M10, 0) + NVL(P.M15, 0) + NVL(P.M20, 0) + NVL(P.M25, 0) +
  620. NVL(P.M30, 0) + NVL(P.M35, 0) + NVL(P.M40, 0) + NVL(P.M45, 0) + NVL(P.M50, 0) + NVL(P.M55, 0) AS TOTAL
  621. FROM HOURS H
  622. LEFT JOIN PIVOTED P ON H.HH = P.HH
  623. ORDER BY H.HH
  624. ]]>
  625. </select>
  626. <select id="getPeriodCenterRcvSendStatistics" parameterType="java.util.HashMap" resultType="com.tsi.monitoring.vo.PeriodCenterRcvSendStatisticsVo">
  627. <![CDATA[
  628. WITH
  629. params AS (
  630. SELECT TO_DATE(CONCAT(#{searchDt}, ' 00:00:00'), 'YYYY-MM-DD HH24:MI:SS') AS start_dt,
  631. TO_DATE(CONCAT(#{searchDt}, ' 23:55:00'), 'YYYY-MM-DD HH24:MI:SS') AS end_dt
  632. FROM dual
  633. ),
  634. slots AS (
  635. SELECT params.start_dt + (LEVEL - 1) * (5/1440) AS slot_dt
  636. FROM params
  637. CONNECT BY params.start_dt + (LEVEL - 1) * (5/1440) <= params.end_dt
  638. ),
  639. logs_rcv AS (
  640. SELECT * FROM RCV_LOG WHERE FROMCENTERID = #{centerId}
  641. ),
  642. logs_snd AS (
  643. SELECT * FROM SND_LOG WHERE TOCENTERID = #{centerId}
  644. ),
  645. logs_moct AS (
  646. SELECT * FROM SND_LOG_MOCT WHERE TOCENTERID = #{centerId}
  647. ),
  648. agg_rcv AS (
  649. SELECT TRUNC(LOGDATE, 'HH24') + FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5) * (5/1440) AS slot_dt,
  650. SUM(CASE WHEN INFOKIND = 'T' THEN DATACNT ELSE 0 END) AS T_CNT,
  651. SUM(CASE WHEN INFOKIND = 'I' THEN DATACNT ELSE 0 END) AS I_CNT
  652. FROM logs_rcv, params
  653. WHERE LOGDATE BETWEEN params.start_dt AND params.end_dt + (5/1440)
  654. GROUP BY TRUNC(LOGDATE, 'HH24') + FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5) * (5/1440)
  655. ),
  656. agg_snd AS (
  657. SELECT TRUNC(LOGDATE, 'HH24') + FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5) * (5/1440) AS slot_dt,
  658. SUM(CASE WHEN INFOKIND = 'T' THEN DATACNT ELSE 0 END) AS T_CNT,
  659. SUM(CASE WHEN INFOKIND = 'I' THEN DATACNT ELSE 0 END) AS I_CNT
  660. FROM logs_snd, params
  661. WHERE LOGDATE BETWEEN params.start_dt AND params.end_dt + (5/1440)
  662. GROUP BY TRUNC(LOGDATE, 'HH24') + FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5) * (5/1440)
  663. ),
  664. agg_moct AS (
  665. SELECT TRUNC(LOGDATE, 'HH24') + FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5) * (5/1440) AS slot_dt,
  666. SUM(NVL(DATACNT, 0)) AS CNT
  667. FROM logs_moct, params
  668. WHERE LOGDATE BETWEEN params.start_dt AND params.end_dt + (5/1440)
  669. GROUP BY TRUNC(LOGDATE, 'HH24') + FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5) * (5/1440)
  670. ),
  671. rcv_final AS (
  672. SELECT s.slot_dt,
  673. NVL(r.T_CNT, 0) AS R_T_CNT,
  674. NVL(r.I_CNT, 0) AS R_I_CNT
  675. FROM slots s
  676. LEFT JOIN agg_rcv r ON s.slot_dt = r.slot_dt
  677. ),
  678. snd_final AS (
  679. SELECT s.slot_dt,
  680. NVL(snd.T_CNT, 0) AS S_T_CNT,
  681. NVL(snd.I_CNT, 0) AS S_I_CNT
  682. FROM slots s
  683. LEFT JOIN agg_snd snd ON s.slot_dt = snd.slot_dt
  684. ),
  685. moct_final AS (
  686. SELECT s.slot_dt, NVL(m.CNT, 0) AS S_M_CNT
  687. FROM slots s
  688. LEFT JOIN agg_moct m ON s.slot_dt = m.slot_dt
  689. )
  690. SELECT TO_CHAR(r.slot_dt, 'YYYY-MM-DD HH24:MI:SS') AS LOG_DATE,
  691. r.R_T_CNT,
  692. r.R_I_CNT,
  693. s.S_T_CNT,
  694. s.S_I_CNT,
  695. m.S_M_CNT
  696. FROM rcv_final r
  697. JOIN snd_final s ON r.slot_dt = s.slot_dt
  698. JOIN moct_final m ON r.slot_dt = m.slot_dt
  699. ORDER BY r.slot_dt
  700. ]]>
  701. </select>
  702. </mapper>