common.xml 27 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679
  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="egovframework.service.mapper.CommonMapper">
  4. <select id="getRoadVertexArr" resultType="egovframework.vo.RoadVertexArrVO" fetchSize="1000">
  5. SELECT
  6. TT.ATRD_ID as atrd_id,
  7. NVL(TT.ATRD_NM, TR.ROAD_NM) as atrd_nm,
  8. DECODE(TT.DRCT_CD,0,'상행','하행') as drct_cd,
  9. TT.ROAD_ORD as road_ord,
  10. NULL as ifsc_ord,
  11. NULL as link_ord,
  12. TR.ROAD_ID as road_id,
  13. TR.ROAD_NM as road_nm,
  14. NVL((SELECT NODE_NAME FROM TB_NODE WHERE TR.F_NODE_ID = NODE_ID),'-') as strt_nm_node,
  15. NVL((SELECT NODE_NAME FROM TB_NODE WHERE TR.T_NODE_ID = NODE_ID),'-') as end_nm_node,
  16. TR.SECT_LNGT as sect_lngt,
  17. TRVA.LEVL as levl,
  18. TRVA.X_CRDN as x_crdn,
  19. TRVA.Y_CRDN as y_crdn,
  20. TRVA.X_CRDN_MIN as x_crdn_min,
  21. TRVA.X_CRDN_MAX as x_crdn_max,
  22. TRVA.Y_CRDN_MIN as y_crdn_min,
  23. TRVA.Y_CRDN_MAX as y_crdn_max,
  24. CASE
  25. WHEN TRT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
  26. THEN TRT.CMTR_GRAD_CD
  27. ELSE 'LTC0'
  28. END cmtr_grad_cd,
  29. CASE
  30. WHEN TRT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
  31. THEN NVL(TRT.SPED,0)
  32. ELSE 0
  33. END sped,
  34. CASE
  35. WHEN TRT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
  36. THEN NVL(ROUND(TRT.TRVL_HH / 60) + 1,0)
  37. ELSE 0
  38. END as trvl_hh
  39. FROM TB_ROAD TR, (SELECT ROAD_ID AS ROAD_ID,
  40. LEVL,
  41. X_CRDN_ARR AS X_CRDN,
  42. Y_CRDN_ARR AS Y_CRDN,
  43. X_CRDN_MIN,
  44. X_CRDN_MAX,
  45. Y_CRDN_MIN,
  46. Y_CRDN_MAX
  47. FROM TB_ROAD_VRTX_ARR
  48. ) TRVA,
  49. TB_ROAD_TRAF TRT, (SELECT T1.ATRD_ID,T1.ATRD_NM,T1.DRCT_CD,T2.ROAD_ID, T2.ORD ROAD_ORD
  50. FROM TB_ATRD T1, TB_ATRD_RLTN_ROAD T2
  51. WHERE T1.ATRD_ID = T2.ATRD_ID
  52. ) TT
  53. WHERE TR.ROAD_ID = TRVA.ROAD_ID
  54. AND TR.ROAD_ID = TRT.ROAD_ID(+)
  55. AND TR.ROAD_ID = TT.ROAD_ID(+)
  56. ORDER BY LEVL,DRCT_CD,ROAD_ORD,IFSC_ORD,LINK_ORD
  57. </select>
  58. <select id="getWeatherInfo" resultType="egovframework.vo.WeatherInfoVO">
  59. SELECT *
  60. FROM
  61. (SELECT
  62. TO_DATE(ANNC_DT, 'YYYYMMDDHH24MISS') AS ANNOUNCEDATE,
  63. 0 AS ANNOUNCETIMECODE,
  64. PRST_TMPR AS TEMPERATURE,
  65. DECODE(WTCD_KOR_NM,
  66. '맑음', 'DB01',
  67. '구름 조금', 'DB02',
  68. '구름 많음', 'DB03',
  69. '흐림', 'DB04',
  70. '비', 'DB05',
  71. '비/눈', 'DB06',
  72. '눈', 'DB07',
  73. '소나기', 'DB08',
  74. 'DB00') AS WEATHERCODE,
  75. LWST_TMPR AS MINTEMPERATURE,
  76. HGHS_TMPR AS MAXTEMPERATURE,
  77. PRST_TMPR
  78. FROM TB_VILG_FRCS_PNST
  79. WHERE ANNC_DT > TO_CHAR(SYSDATE - 1, 'YYYYMMDDHH24MISS')
  80. --AND VILG_FRCS_ZONE_CD = 4146151000
  81. AND VILG_FRCS_ZONE_CD = 4122000000
  82. ORDER BY ORD DESC)
  83. WHERE ROWNUM = 1
  84. </select>
  85. <select id="getIfscVertexArr" resultType="egovframework.vo.RoadVertexArrVO" fetchSize="7000">
  86. SELECT
  87. TT.ATRD_ID,
  88. NVL(TT.ATRD_NM,TI.IFSC_NM) ATRD_NM,
  89. DECODE(TT.DRCT_CD,0,'상행','하행') DRCT_CD,
  90. TT.ROAD_ORD,
  91. TT.IFSC_ORD,
  92. NULL LINK_ORD,
  93. TI.IFSC_ID ROAD_ID,
  94. TI.IFSC_NM ROAD_NM,
  95. NVL((SELECT NODE_NAME FROM TB_NODE WHERE TI.F_NODE_ID = NODE_ID),'-') STRT_NM_NODE,
  96. NVL((SELECT NODE_NAME FROM TB_NODE WHERE TI.T_NODE_ID = NODE_ID),'-') END_NM_NODE,
  97. TI.SECT_LNGT SECT_LNGT,
  98. TIVA.LEVL,
  99. TIVA.X_CRDN,
  100. TIVA.Y_CRDN,
  101. TIVA.X_CRDN_MIN,
  102. TIVA.X_CRDN_MAX,
  103. TIVA.Y_CRDN_MIN,
  104. TIVA.Y_CRDN_MAX,
  105. CASE WHEN TIT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
  106. THEN TIT.CMTR_GRAD_CD
  107. ELSE 'LTC0'
  108. END CMTR_GRAD_CD,
  109. CASE WHEN TIT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
  110. THEN NVL(TIT.SPED,0)
  111. ELSE 0
  112. END SPED,
  113. CASE WHEN TIT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
  114. THEN NVL(ROUND(TIT.TRVL_HH / 60) + 1,0)
  115. ELSE 0
  116. END TRVL_HH
  117. FROM
  118. TB_IFSC TI,
  119. (SELECT
  120. IFSC_ID,
  121. LEVL,
  122. X_CRDN_ARR AS X_CRDN,
  123. Y_CRDN_ARR AS Y_CRDN,
  124. X_CRDN_MIN,
  125. X_CRDN_MAX,
  126. Y_CRDN_MIN,
  127. Y_CRDN_MAX
  128. FROM TB_IFSC_VRTX_ARR) TIVA, TB_IFSC_TRAF TIT,
  129. (
  130. SELECT T1.ATRD_ID,T1.ATRD_NM,T1.DRCT_CD,T2.ORD ROAD_ORD,T3.IFSC_ID,T3.ORD IFSC_ORD
  131. FROM TB_ATRD T1, TB_ATRD_RLTN_ROAD T2, TB_ROAD_RLTN_IFSC T3
  132. WHERE T1.ATRD_ID = T2.ATRD_ID
  133. AND T2.ROAD_ID = T3.ROAD_ID
  134. ) TT
  135. WHERE TI.IFSC_ID = TIVA.IFSC_ID
  136. AND TI.IFSC_ID = TIT.IFSC_ID(+)
  137. AND TI.IFSC_ID = TT.IFSC_ID(+)
  138. ORDER BY LEVL,DRCT_CD,ROAD_ORD,IFSC_ORD,LINK_ORD
  139. </select>
  140. <select id="getLinkVertexArr" resultType="egovframework.vo.RoadVertexArrVO" fetchSize="12000">
  141. SELECT
  142. TT.ATRD_ID,
  143. NVL(TT.ATRD_NM,TL.ROAD_NAME) ATRD_NM,
  144. DECODE(TT.DRCT_CD,0,'상행','하행') DRCT_CD,
  145. TT.ROAD_ORD,
  146. TT.IFSC_ORD,
  147. TT.LINK_ORD,
  148. TL.LINK_ID ROAD_ID,
  149. TL.ROAD_NAME ROAD_NM,
  150. NVL((SELECT NODE_NAME FROM TB_NODE WHERE TL.F_NODE_ID = NODE_ID),'-') STRT_NM_NODE,
  151. NVL((SELECT NODE_NAME FROM TB_NODE WHERE TL.T_NODE_ID = NODE_ID),'-') END_NM_NODE,
  152. 0 SECT_LNGT,
  153. TLVA.LEVL,
  154. TLVA.X_CRDN,
  155. TLVA.Y_CRDN,
  156. TLVA.X_CRDN_MIN,
  157. TLVA.X_CRDN_MAX,
  158. TLVA.Y_CRDN_MIN,
  159. TLVA.Y_CRDN_MAX,
  160. CASE WHEN TLT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
  161. THEN TLT.CMTR_GRAD_CD
  162. ELSE 'LTC0'
  163. END CMTR_GRAD_CD,
  164. CASE WHEN TLT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
  165. THEN NVL(TLT.SPED,0)
  166. ELSE 0
  167. END SPED,
  168. CASE WHEN TLT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
  169. THEN NVL(ROUND(TLT.TRVL_HH / 60) + 1,0)
  170. ELSE 0
  171. END TRVL_HH
  172. FROM TB_LINK TL, (SELECT
  173. LINK_ID,
  174. LEVL,
  175. X_CRDN_ARR AS X_CRDN,
  176. Y_CRDN_ARR AS Y_CRDN,
  177. X_CRDN_MIN,
  178. X_CRDN_MAX,
  179. Y_CRDN_MIN,
  180. Y_CRDN_MAX
  181. FROM TB_LINK_VRTX_ARR
  182. ) TLVA, TB_LINK_TRAF TLT, (SELECT T1.ATRD_ID,T1.ATRD_NM,T1.DRCT_CD,T2.ORD ROAD_ORD,T3.ORD IFSC_ORD,T4.ORD LINK_ORD,T4.LINK_ID
  183. FROM TB_ATRD T1, TB_ATRD_RLTN_ROAD T2, TB_ROAD_RLTN_IFSC T3, TB_IFSC_RLTN_LINK T4
  184. WHERE T1.ATRD_ID = T2.ATRD_ID
  185. AND T2.ROAD_ID = T3.ROAD_ID
  186. AND T3.IFSC_ID = T4.IFSC_ID
  187. ) TT
  188. WHERE TL.LINK_ID = TLVA.LINK_ID
  189. AND TL.LINK_ID = TLT.LINK_ID(+)
  190. AND TL.LINK_ID = TT.LINK_ID(+)
  191. AND TLVA.LEVL <![CDATA[ = ]]> 2
  192. ORDER BY LEVL,DRCT_CD,ROAD_ORD,IFSC_ORD,LINK_ORD
  193. </select>
  194. <select id="getVertexArr" resultType="egovframework.vo.RoadVertexArrVO" fetchSize="1000">
  195. SELECT
  196. TT.ATRD_ID,
  197. NVL(TT.ATRD_NM,'-') ATRD_NM,
  198. DECODE(TT.DRCT_CD,0,'상행','하행') DRCT_CD,
  199. TT.ROAD_ORD,
  200. TT.IFSC_ORD,
  201. TT.LINK_ORD,
  202. TL.LINK_ID ROAD_ID,
  203. TL.ROAD_NAME ROAD_NM,
  204. NVL((SELECT NODE_NAME FROM TB_NODE WHERE TL.F_NODE = NODE_ID),'-') STRT_NM_NODE,
  205. NVL((SELECT NODE_NAME FROM TB_NODE WHERE TL.T_NODE = NODE_ID),'-') END_NM_NODE,
  206. 0 SECT_LNGT,
  207. TLVA.LEVL,
  208. TLVA.X_CRDN,
  209. TLVA.Y_CRDN,
  210. TLVA.X_CRDN_MIN,
  211. TLVA.X_CRDN_MAX,
  212. TLVA.Y_CRDN_MIN,
  213. TLVA.Y_CRDN_MAX,
  214. CASE WHEN TLT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
  215. THEN TLT.CMTR_GRAD_CD
  216. ELSE 'LTC0'
  217. END CMTR_GRAD_CD,
  218. CASE WHEN TLT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
  219. THEN NVL(TLT.SPED,0)
  220. ELSE 0
  221. END SPED,
  222. CASE WHEN TLT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
  223. THEN NVL(ROUND(TLT.TRVL_HH / 60) + 1,0)
  224. ELSE 0
  225. END TRVL_HH
  226. FROM
  227. TB_LINK TL,
  228. (SELECT
  229. LINK_ID,
  230. LEVL,
  231. X_CRDN_ARR AS X_CRDN,
  232. Y_CRDN_ARR AS Y_CRDN,
  233. X_CRDN_MIN,
  234. X_CRDN_MAX,
  235. Y_CRDN_MIN,
  236. Y_CRDN_MAX
  237. FROM TB_LINK_VRTX_ARR) TLVA, TB_LINK_TRAF TLT,
  238. (
  239. SELECT T1.ATRD_ID,T1.ATRD_NM,T1.DRCT_CD,T2.ORD ROAD_ORD,T3.ORD IFSC_ORD,T4.ORD LINK_ORD,T4.LINK_ID
  240. FROM TB_ATRD T1, TB_ATRD_ROAD_RLTN T2, TB_ROAD_IFSC_RLTN T3, TB_IFSC_LINK_RLTN T4
  241. WHERE T1.ATRD_ID = T2.ATRD_ID
  242. AND T2.ROAD_ID = T3.ROAD_ID
  243. AND T3.IFSC_ID = T4.IFSC_ID
  244. ) TT
  245. WHERE TL.LINK_ID = TLVA.LINK_ID
  246. AND TL.LINK_ID = TLT.LINK_ID(+)
  247. AND TL.LINK_ID = TT.LINK_ID(+)
  248. UNION ALL
  249. SELECT
  250. TT.ATRD_ID,
  251. NVL(TT.ATRD_NM,'-') ATRD_NM,
  252. DECODE(TT.DRCT_CD,0,'상행','하행') DRCT_CD,
  253. TT.ROAD_ORD,
  254. TT.IFSC_ORD,
  255. NULL LINK_ORD,
  256. TI.IFSC_ID ROAD_ID,
  257. TI.IFSC_NM ROAD_NM,
  258. NVL((SELECT NODE_NAME FROM TB_NODE WHERE TI.F_NODE_ID = NODE_ID),'-') STRT_NM_NODE,
  259. NVL((SELECT NODE_NAME FROM TB_NODE WHERE TI.T_NODE_ID = NODE_ID),'-') END_NM_NODE,
  260. TI.SECT_LNGT SECT_LNGT,
  261. TIVA.LEVL,
  262. TIVA.X_CRDN,
  263. TIVA.Y_CRDN,
  264. TIVA.X_CRDN_MIN,
  265. TIVA.X_CRDN_MAX,
  266. TIVA.Y_CRDN_MIN,
  267. TIVA.Y_CRDN_MAX,
  268. CASE WHEN TIT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
  269. THEN TIT.CMTR_GRAD_CD
  270. ELSE 'LTC0'
  271. END CMTR_GRAD_CD,
  272. CASE WHEN TIT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
  273. THEN NVL(TIT.SPED,0)
  274. ELSE 0
  275. END SPED,
  276. CASE WHEN TIT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
  277. THEN NVL(ROUND(TIT.TRVL_HH / 60) + 1,0)
  278. ELSE 0
  279. END TRVL_HH
  280. FROM
  281. TB_IFSC TI,
  282. (SELECT
  283. IFSC_ID,
  284. LEVL,
  285. X_CRDN_ARR AS X_CRDN,
  286. Y_CRDN_ARR AS Y_CRDN,
  287. X_CRDN_MIN,
  288. X_CRDN_MAX,
  289. Y_CRDN_MIN,
  290. Y_CRDN_MAX
  291. FROM TB_IFSC_VRTX_ARR) TIVA, TB_IFSC_TRAF TIT,
  292. (
  293. SELECT T1.ATRD_ID,T1.ATRD_NM,T1.DRCT_CD,T2.ORD ROAD_ORD,T3.IFSC_ID,T3.ORD IFSC_ORD
  294. FROM TB_ATRD T1, TB_ATRD_ROAD_RLTN T2, TB_ROAD_IFSC_RLTN T3
  295. WHERE T1.ATRD_ID = T2.ATRD_ID
  296. AND T2.ROAD_ID = T3.ROAD_ID
  297. ) TT
  298. WHERE TI.IFSC_ID = TIVA.IFSC_ID
  299. AND TI.IFSC_ID = TIT.IFSC_ID(+)
  300. AND TI.IFSC_ID = TT.IFSC_ID(+)
  301. UNION ALL
  302. SELECT
  303. TT.ATRD_ID,
  304. NVL(TT.ATRD_NM,'-') ATRD_NM,
  305. DECODE(TT.DRCT_CD,0,'상행','하행') DRCT_CD,
  306. TT.ROAD_ORD,
  307. NULL IFSC_ORD,
  308. NULL LINK_ORD,
  309. TR.ROAD_ID ROAD_ID,
  310. TR.ROAD_NAME ROAD_NAME,
  311. NVL((SELECT NODE_NAME FROM TB_NODE WHERE TR.F_NODE_ID = NODE_ID),'-') STRT_NM_NODE,
  312. NVL((SELECT NODE_NAME FROM TB_NODE WHERE TR.T_NODE_ID = NODE_ID),'-') END_NM_NODE,
  313. TR.SECT_LNGT,
  314. TRVA.LEVL,
  315. TRVA.X_CRDN,
  316. TRVA.Y_CRDN,
  317. TRVA.X_CRDN_MIN,
  318. TRVA.X_CRDN_MAX,
  319. TRVA.Y_CRDN_MIN,
  320. TRVA.Y_CRDN_MAX,
  321. CASE WHEN TRT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
  322. THEN TRT.CMTR_GRAD_CD
  323. ELSE 'LTC0'
  324. END CMTR_GRAD_CD,
  325. CASE WHEN TRT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
  326. THEN NVL(TRT.SPED,0)
  327. ELSE 0
  328. END SPED,
  329. CASE WHEN TRT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
  330. THEN NVL(ROUND(TRT.TRVL_HH / 60) + 1,0)
  331. ELSE 0
  332. END TRVL_HH
  333. FROM
  334. TB_ROAD TR,
  335. (SELECT
  336. ROAD_ID AS ROAD_ID,
  337. LEVL,
  338. X_CRDN_ARR AS X_CRDN,
  339. Y_CRDN_ARR AS Y_CRDN,
  340. X_CRDN_MIN,
  341. X_CRDN_MAX,
  342. Y_CRDN_MIN,
  343. Y_CRDN_MAX
  344. FROM TB_ROAD_VRTX_ARR) TRVA, TB_ROAD_TRAF TRT,
  345. (SELECT T1.ATRD_ID,T1.ATRD_NM,T1.DRCT_CD,T2.ROAD_ID, T2.ORD ROAD_ORD
  346. FROM TB_ATRD T1, TB_ATRD_ROAD_RLTN T2
  347. WHERE T1.ATRD_ID = T2.ATRD_ID
  348. ) TT
  349. WHERE TR.ROAD_ID = TRVA.ROAD_ID
  350. AND TR.ROAD_ID = TRT.ROAD_ID(+)
  351. AND TR.ROAD_ID = TT.ROAD_ID(+)
  352. ORDER BY LEVL,DRCT_CD,ROAD_ORD,IFSC_ORD,LINK_ORD
  353. </select>
  354. <select id="getVmsCtlr" resultType="egovframework.vo.VmsCtlrVO">
  355. SELECT A.VMS_CTLR_NMBR,
  356. A.VMS_NM,
  357. A.X_CRDN,
  358. A.Y_CRDN,
  359. NVL(B.CMNC_STTS_CD, 'CMS1') AS CMNC_STTS_CD
  360. FROM TB_VMS_CTLR A
  361. LEFT OUTER JOIN TB_VMS_CTLR_STTS B
  362. ON A.VMS_CTLR_NMBR = B.VMS_CTLR_NMBR
  363. WHERE A.DEL_YN = 'N'
  364. ORDER BY A.VMS_NM ASC
  365. </select>
  366. <select id="getVmsPhaseImgList" resultType="egovframework.vo.VmsCtlrVO">
  367. SELECT A.VMS_CTLR_NMBR,
  368. A.PHASE,
  369. A.VMS_DSPL_MSG_IMAG,
  370. A.VMS_DSPL_MSG_TXT
  371. FROM TB_VMS_DSPL_PRST A,
  372. (SELECT VMS_CTLR_NMBR, MAX(DSPL_DT) AS DSPL_DT
  373. FROM TB_VMS_DSPL_PRST
  374. WHERE DSPL_DT >= TO_CHAR((SYSDATE - 8/1440),'YYYYMMDDHH24MISS')
  375. GROUP by VMS_CTLR_NMBR) B
  376. WHERE A.VMS_CTLR_NMBR = B.VMS_CTLR_NMBR
  377. AND A.DSPL_DT = B.DSPL_DT
  378. ORDER BY A.VMS_CTLR_NMBR, A.PHASE
  379. </select>
  380. <select id="getVmsImgTxt" resultType="egovframework.vo.VmsCtlrVO" parameterType="java.util.HashMap">
  381. SELECT
  382. A.VMS_CTLR_NMBR,
  383. B.VMS_WDTH AS phas_img_width,
  384. B.VMS_HGHT AS phas_img_height,
  385. C.PHASE,
  386. C.VMS_DSPL_MSG_IMAG,
  387. C.VMS_DSPL_MSG_TXT
  388. --,NVL((SELECT CMNC_STTS_CD
  389. -- FROM TB_VMS_CTLR_STTS
  390. -- WHERE VMS_CTLR_NMBR = A.VMS_CTLR_NMBR
  391. -- AND UPDT_DT >= TO_CHAR((SYSDATE - 8/1440),'YYYYMMDDHH24MISS')), 'CMS1') AS CMNC_STTS_CD
  392. FROM TB_VMS_CTLR A
  393. INNER JOIN TB_VMS_TYPE B
  394. ON A.VMS_CTLR_NMBR = #{vms_ctlr_nmbr}
  395. AND A.VMS_TYPE_CD = B.VMS_TYPE_CD
  396. LEFT OUTER JOIN (SELECT
  397. VMS_CTLR_NMBR,
  398. PHASE,
  399. VMS_DSPL_MSG_IMAG,
  400. VMS_DSPL_MSG_TXT
  401. FROM TB_VMS_DSPL_PRST
  402. WHERE (VMS_CTLR_NMBR, DSPL_DT)
  403. IN
  404. (SELECT
  405. VMS_CTLR_NMBR,
  406. MAX(DSPL_DT) AS DSPL_DT
  407. FROM TB_VMS_DSPL_PRST
  408. WHERE VMS_CTLR_NMBR = #{vms_ctlr_nmbr}
  409. AND DSPL_DT >= TO_CHAR((SYSDATE - 8/1440),'YYYYMMDDHH24MISS')
  410. GROUP BY VMS_CTLR_NMBR
  411. )
  412. ) C
  413. ON A.VMS_CTLR_NMBR = C.VMS_CTLR_NMBR
  414. </select>
  415. <select id="getWcamCtlr" resultType="egovframework.vo.WcamCtlrVO">
  416. SELECT WCAM_CTLR_NMBR,
  417. WCAM_NM,
  418. WCAM_TYPE_CD,
  419. NVL(ISTL_LCTN_NM,'-') ISTL_LCTN_NM,
  420. X_CRDN,
  421. Y_CRDN,
  422. STRM_RTSP_ADDR,
  423. STRM_RTMP_ADDR,
  424. STRM_HTTP_ADDR
  425. FROM TB_WCAM_CTLR
  426. WHERE DEL_YN = 'N'
  427. </select>
  428. <select id="getCctvCtlr" resultType="egovframework.vo.CctvCtlrVO">
  429. SELECT A.CCTV_CTLR_NMBR as cctv_mngm_nmbr,
  430. A.CCTV_CTLR_ID as cctv_ctlr_id,
  431. A.CCTV_CTLR_IP as cctv_ctlr_ip,
  432. A.CCTV_CTLR_PORT as cctv_ctlr_port,
  433. A.CCTV_CAPT_IP as cctv_capt_ip,
  434. A.CCTV_CAPT_PORT as cctv_capt_port,
  435. --A.CCTV_FIBR_IP as cctv_fibr_ip,
  436. --A.CCTV_ENCD_IP as cctv_encd_ip,
  437. A.STRM_SVR_IP as strm_svr_ip,
  438. A.STRM_SVR_PORT as strm_svr_port,
  439. A.STRM_SESN_NM as strm_sesn_nm,
  440. A.X_CRDN as x_crdn,
  441. A.Y_CRDN as y_crdn,
  442. A.ISTL_LCTN_NM as istl_lctn_nm,
  443. A.ISTL_LCTN_ADDR as istl_lctn_addr,
  444. --A.CCTV_CHNL as cctv_chnl,
  445. A.DEL_YN as del_yn,
  446. A.LINK_ID as link_id,
  447. A.NODE_ID as node_id,
  448. --A.RELY_PORT as rely_port,
  449. A.STRM_RTSP_ADDR as strm_rtsp_addr,
  450. --A.STRM_RTMP_ADDR as strm_rtmp_addr,
  451. A.STRM_HTTP_ADDR as strm_http_addr,
  452. --A.STRM_STOR_ADDR as strm_stor_addr,
  453. --A.AREA_CD as area_cd,
  454. B.CMNC_STTS_CD as cmnc_stts_cd,
  455. A.WEB_RTC_SVR_PORT as web_rtc_svr_port,
  456. A.WEB_RTC_SVR_IP as web_rtc_svr_ip,
  457. A.WEB_RTC_ID as web_rtc_id
  458. FROM TB_CCTV_CTLR A
  459. LEFT OUTER JOIN TB_CCTV_CTLR_STTS B
  460. ON A.CCTV_CTLR_NMBR = B.CCTV_CTLR_NMBR
  461. WHERE A.DEL_YN = 'N'
  462. ORDER BY A.ISTL_LCTN_NM ASC
  463. </select>
  464. <select id="getOneCctvCtlr" resultType="egovframework.vo.CctvCtlrVO" parameterType="String">
  465. SELECT
  466. A.CCTV_CTLR_NMBR as cctv_mngm_nmbr,
  467. A.CCTV_CTLR_ID as cctv_ctlr_id,
  468. A.CCTV_CTLR_IP as cctv_ctlr_ip,
  469. A.CCTV_CTLR_PORT as cctv_ctlr_port,
  470. A.CCTV_CAPT_IP as cctv_capt_ip,
  471. A.CCTV_CAPT_PORT as cctv_capt_port,
  472. --A.CCTV_FIBR_IP as cctv_fibr_ip,
  473. --A.CCTV_ENCD_IP as cctv_encd_ip,
  474. A.STRM_SVR_IP as strm_svr_ip,
  475. A.STRM_SVR_PORT as strm_svr_port,
  476. A.STRM_SESN_NM as strm_sesn_nm,
  477. A.X_CRDN as x_crdn,
  478. A.Y_CRDN as y_crdn,
  479. A.ISTL_LCTN_NM as istl_lctn_nm,
  480. A.ISTL_LCTN_ADDR as istl_lctn_addr,
  481. --A.CCTV_CHNL as cctv_chnl,
  482. A.DEL_YN as del_yn,
  483. A.LINK_ID as link_id,
  484. A.NODE_ID as node_id,
  485. --A.RELY_PORT as rely_port,
  486. A.STRM_RTSP_ADDR as strm_rtsp_addr,
  487. --A.STRM_RTMP_ADDR as strm_rtmp_addr,
  488. A.STRM_HTTP_ADDR as strm_http_addr,
  489. --A.STRM_STOR_ADDR as strm_stor_addr,
  490. --A.AREA_CD as area_cd,
  491. B.CMNC_STTS_CD as cmnc_stts_cd,
  492. A.WEB_RTC_SVR_PORT as web_rtc_svr_port,
  493. A.WEB_RTC_SVR_IP as web_rtc_svr_ip,
  494. A.WEB_RTC_ID as web_rtc_id
  495. FROM
  496. TB_CCTV_CTLR A LEFT OUTER JOIN TB_CCTV_CTLR_STTS B
  497. ON A.CCTV_CTLR_NMBR = B.CCTV_CTLR_NMBR
  498. WHERE A.DEL_YN = 'N'
  499. AND A.CCTV_CTLR_NMBR = #{nmbr}
  500. ORDER BY ISTL_LCTN_NM ASC
  501. </select>
  502. <select id="getIncdOcrr" resultType="egovframework.vo.IncdVO">
  503. SELECT A.INCD_OCRR_ID as incd_ocrr_id,
  504. A.LINK_ID as link_id,
  505. SUBSTR(A.INCD_STRT_DT, 0,4) || '년' ||
  506. SUBSTR(A.INCD_STRT_DT, 5,2) || '월' ||
  507. SUBSTR(A.INCD_STRT_DT, 7,2) || '일 ' ||
  508. SUBSTR(A.INCD_STRT_DT, 9,2) || '시' as incd_strt_dt,
  509. SUBSTR(A.INCD_END_PRAR_DT, 0,4) || '년' ||
  510. SUBSTR(A.INCD_END_PRAR_DT, 5,2) || '월' ||
  511. SUBSTR(A.INCD_END_PRAR_DT, 7,2) || '일 ' ||
  512. SUBSTR(A.INCD_END_PRAR_DT, 9,2) || '시' as incd_end_prar_dt,
  513. A.OCRR_LCTN_NM AS road_name,
  514. NVL(TRIM(A.INCD_TITL),'-') AS incd_titl,
  515. NVL(TRIM(A.INCD_EXPL),'-') AS incd_expl,
  516. DECODE(A.INCD_TYPE_CLSF_CD,'1','01','2','02','3','03','4','04') AS incd_type_code,
  517. B.CMMN_CD_KOR_NM as cmmn_cd_kor_nm,
  518. A.X_CRDN as x_crdn,
  519. A.Y_CRDN as y_crdn
  520. FROM TB_INCD_OCRR A, TB_CMMN_CD B
  521. WHERE A.INCD_PRGR_STEP_CD = 'ISS2'
  522. AND B.CMMN_CLSF_CD = 'IDTU'
  523. AND A.INCD_TYPE_CLSF_CD = B.CMMN_CD
  524. ORDER BY ROAD_NAME
  525. </select>
  526. <select id="getAtrdNm" resultType="egovframework.vo.AtrdVO">
  527. <!-- (오라클) WM_CONCAT : 여러행 데이터를 하나의 컬럼으로..
  528. Oracle 10g에서 사용
  529. -->
  530. -- SELECT ATRD_NM as atrd_nm,
  531. -- WM_CONCAT(ATRD_ID) as atrd_id
  532. -- FROM TB_ATRD
  533. -- WHERE DEL_YN = 'N'
  534. -- GROUP BY ATRD_NM
  535. <!-- (오라클) LISTAGG : 여러행 데이터를 하나의 컬럼으로..
  536. Oracle XE 11g 이상에서는 WM_CONCAT() 사용을 못하고,
  537. 대신에 LISTAGG 사용하면 된다.
  538. -->
  539. SELECT ATRD_NM as atrd_nm,
  540. LISTAGG(ATRD_ID,',') as atrd_id
  541. FROM TB_ATRD
  542. WHERE DEL_YN = 'N'
  543. GROUP BY ATRD_NM ORDER BY ATRD_NM
  544. <!-- (티베로) AGGR_CONCAT : 여러행 데이터를 하나의 컬럼으로..
  545. SELECT ATRD_NM as atrd_nm,
  546. AGGR_CONCAT(ATRD_ID,',') as atrd_id,
  547. FROM TB_ATRD
  548. WHERE DEL_YN = 'N'
  549. GROUP BY ATRD_NM ;
  550. -->
  551. </select>
  552. <select id="getVisitCount" resultType="egovframework.vo.VisitCountVO">
  553. SELECT SUM(TODAY) AS TODAY,
  554. SUM(TOTAL) AS TOTAL
  555. FROM (SELECT NVL(SUM(CONN_CNT), 1) AS TODAY, 0 AS TOTAL
  556. FROM TB_WWW_CONN_PAGE_STAT_DD t
  557. WHERE T.STAT_MON = TO_CHAR(SYSDATE, 'YYYYMM')
  558. AND T.STAT_DD = TO_CHAR(SYSDATE, 'DD')
  559. AND T.PAGE_ID = 'W1'
  560. UNION ALL
  561. SELECT 0 AS TODAY, NVL(SUM(CONN_CNT), 1) AS TOTAL
  562. FROM TB_WWW_CONN_PAGE_STAT_MN T
  563. WHERE T.PAGE_ID = 'W1'
  564. )
  565. </select>
  566. <update id="insertUpdateHourLogWeb" parameterType="java.util.HashMap">
  567. MERGE INTO
  568. TB_WWW_CONN_PAGE_STAT_HH
  569. USING
  570. DUAL
  571. ON
  572. (
  573. STAT_DAY = TO_CHAR (SYSDATE, 'YYYYMMDD')
  574. AND STAT_HH = TO_CHAR (SYSDATE, 'HH24')
  575. AND PAGE_ID = (SELECT PAGE_ID FROM TB_WWW_PAGE WHERE PAGE_URL = #{uri})
  576. )
  577. WHEN MATCHED THEN
  578. UPDATE SET
  579. CONN_CNT = CONN_CNT + 1
  580. WHEN NOT MATCHED THEN
  581. INSERT(
  582. CONN_CNT,
  583. PAGE_ID,
  584. STAT_HH,
  585. STAT_DAY
  586. )
  587. VALUES(
  588. 1,
  589. (SELECT PAGE_ID FROM TB_WWW_PAGE WHERE PAGE_URL = #{uri}),
  590. TO_CHAR (SYSDATE, 'HH24'),
  591. TO_CHAR (SYSDATE, 'YYYYMMDD')
  592. )
  593. </update>
  594. <update id="insertUpdateDateLogWeb" parameterType="java.util.HashMap">
  595. MERGE INTO
  596. TB_WWW_CONN_PAGE_STAT_DD
  597. USING
  598. DUAL ON
  599. (
  600. STAT_MON = TO_CHAR (SYSDATE, 'YYYYMM')
  601. AND STAT_DD = TO_CHAR (SYSDATE, 'DD')
  602. AND PAGE_ID = (SELECT PAGE_ID FROM TB_WWW_PAGE WHERE PAGE_URL = #{uri})
  603. )
  604. WHEN
  605. MATCHED THEN
  606. UPDATE SET CONN_CNT = CONN_CNT + 1
  607. WHEN
  608. NOT MATCHED THEN
  609. INSERT
  610. (
  611. CONN_CNT,
  612. PAGE_ID,
  613. STAT_DD,
  614. STAT_MON
  615. )
  616. VALUES
  617. (
  618. 1,
  619. (SELECT PAGE_ID FROM TB_WWW_PAGE WHERE PAGE_URL = #{uri}),
  620. TO_CHAR (SYSDATE, 'DD'),
  621. TO_CHAR (SYSDATE, 'YYYYMM')
  622. )
  623. </update>
  624. <update id="insertUpdateMonthLogWeb" parameterType="java.util.HashMap">
  625. MERGE INTO
  626. TB_WWW_CONN_PAGE_STAT_MN
  627. USING
  628. DUAL ON
  629. (
  630. STAT_YEAR = TO_CHAR(SYSDATE, 'YYYY')
  631. AND STAT_MN = TO_CHAR(SYSDATE, 'MM')
  632. AND PAGE_ID = (SELECT PAGE_ID FROM TB_WWW_PAGE WHERE PAGE_URL = #{uri})
  633. )
  634. WHEN
  635. MATCHED THEN
  636. UPDATE SET CONN_CNT = CONN_CNT + 1
  637. WHEN
  638. NOT MATCHED THEN
  639. INSERT
  640. (
  641. CONN_CNT,
  642. PAGE_ID,
  643. STAT_MN,
  644. STAT_YEAR
  645. )
  646. VALUES
  647. (
  648. 1,
  649. (SELECT PAGE_ID FROM TB_WWW_PAGE WHERE PAGE_URL = #{uri}),
  650. TO_CHAR(SYSDATE, 'MM'),
  651. TO_CHAR(SYSDATE, 'YYYY')
  652. )
  653. </update>
  654. </mapper>