| 123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679 |
- <?xml version="1.0" encoding="UTF-8"?>
- <!DOCTYPE mapper PUBLIC "-//mybatis.org//DTD Mapper 3.0//EN" "http://mybatis.org/dtd/mybatis-3-mapper.dtd">
- <mapper namespace="egovframework.service.mapper.CommonMapper">
- <select id="getRoadVertexArr" resultType="egovframework.vo.RoadVertexArrVO" fetchSize="1000">
- SELECT
- TT.ATRD_ID as atrd_id,
- NVL(TT.ATRD_NM, TR.ROAD_NM) as atrd_nm,
- DECODE(TT.DRCT_CD,0,'상행','하행') as drct_cd,
- TT.ROAD_ORD as road_ord,
- NULL as ifsc_ord,
- NULL as link_ord,
- TR.ROAD_ID as road_id,
- TR.ROAD_NM as road_nm,
- NVL((SELECT NODE_NAME FROM TB_NODE WHERE TR.F_NODE_ID = NODE_ID),'-') as strt_nm_node,
- NVL((SELECT NODE_NAME FROM TB_NODE WHERE TR.T_NODE_ID = NODE_ID),'-') as end_nm_node,
- TR.SECT_LNGT as sect_lngt,
- TRVA.LEVL as levl,
- TRVA.X_CRDN as x_crdn,
- TRVA.Y_CRDN as y_crdn,
- TRVA.X_CRDN_MIN as x_crdn_min,
- TRVA.X_CRDN_MAX as x_crdn_max,
- TRVA.Y_CRDN_MIN as y_crdn_min,
- TRVA.Y_CRDN_MAX as y_crdn_max,
- CASE
- WHEN TRT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
- THEN TRT.CMTR_GRAD_CD
- ELSE 'LTC0'
- END cmtr_grad_cd,
- CASE
- WHEN TRT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
- THEN NVL(TRT.SPED,0)
- ELSE 0
- END sped,
- CASE
- WHEN TRT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
- THEN NVL(ROUND(TRT.TRVL_HH / 60) + 1,0)
- ELSE 0
- END as trvl_hh
- FROM TB_ROAD TR, (SELECT ROAD_ID AS ROAD_ID,
- LEVL,
- X_CRDN_ARR AS X_CRDN,
- Y_CRDN_ARR AS Y_CRDN,
- X_CRDN_MIN,
- X_CRDN_MAX,
- Y_CRDN_MIN,
- Y_CRDN_MAX
- FROM TB_ROAD_VRTX_ARR
- ) TRVA,
- TB_ROAD_TRAF TRT, (SELECT T1.ATRD_ID,T1.ATRD_NM,T1.DRCT_CD,T2.ROAD_ID, T2.ORD ROAD_ORD
- FROM TB_ATRD T1, TB_ATRD_RLTN_ROAD T2
- WHERE T1.ATRD_ID = T2.ATRD_ID
- ) TT
- WHERE TR.ROAD_ID = TRVA.ROAD_ID
- AND TR.ROAD_ID = TRT.ROAD_ID(+)
- AND TR.ROAD_ID = TT.ROAD_ID(+)
- ORDER BY LEVL,DRCT_CD,ROAD_ORD,IFSC_ORD,LINK_ORD
- </select>
- <select id="getWeatherInfo" resultType="egovframework.vo.WeatherInfoVO">
- SELECT *
- FROM
- (SELECT
- TO_DATE(ANNC_DT, 'YYYYMMDDHH24MISS') AS ANNOUNCEDATE,
- 0 AS ANNOUNCETIMECODE,
- PRST_TMPR AS TEMPERATURE,
- DECODE(WTCD_KOR_NM,
- '맑음', 'DB01',
- '구름 조금', 'DB02',
- '구름 많음', 'DB03',
- '흐림', 'DB04',
- '비', 'DB05',
- '비/눈', 'DB06',
- '눈', 'DB07',
- '소나기', 'DB08',
- 'DB00') AS WEATHERCODE,
- LWST_TMPR AS MINTEMPERATURE,
- HGHS_TMPR AS MAXTEMPERATURE,
- PRST_TMPR
- FROM TB_VILG_FRCS_PNST
- WHERE ANNC_DT > TO_CHAR(SYSDATE - 1, 'YYYYMMDDHH24MISS')
- --AND VILG_FRCS_ZONE_CD = 4146151000
- AND VILG_FRCS_ZONE_CD = 4122000000
- ORDER BY ORD DESC)
- WHERE ROWNUM = 1
- </select>
-
- <select id="getIfscVertexArr" resultType="egovframework.vo.RoadVertexArrVO" fetchSize="7000">
- SELECT
- TT.ATRD_ID,
- NVL(TT.ATRD_NM,TI.IFSC_NM) ATRD_NM,
- DECODE(TT.DRCT_CD,0,'상행','하행') DRCT_CD,
- TT.ROAD_ORD,
- TT.IFSC_ORD,
- NULL LINK_ORD,
- TI.IFSC_ID ROAD_ID,
- TI.IFSC_NM ROAD_NM,
- NVL((SELECT NODE_NAME FROM TB_NODE WHERE TI.F_NODE_ID = NODE_ID),'-') STRT_NM_NODE,
- NVL((SELECT NODE_NAME FROM TB_NODE WHERE TI.T_NODE_ID = NODE_ID),'-') END_NM_NODE,
- TI.SECT_LNGT SECT_LNGT,
- TIVA.LEVL,
- TIVA.X_CRDN,
- TIVA.Y_CRDN,
- TIVA.X_CRDN_MIN,
- TIVA.X_CRDN_MAX,
- TIVA.Y_CRDN_MIN,
- TIVA.Y_CRDN_MAX,
- CASE WHEN TIT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
- THEN TIT.CMTR_GRAD_CD
- ELSE 'LTC0'
- END CMTR_GRAD_CD,
- CASE WHEN TIT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
- THEN NVL(TIT.SPED,0)
- ELSE 0
- END SPED,
- CASE WHEN TIT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
- THEN NVL(ROUND(TIT.TRVL_HH / 60) + 1,0)
- ELSE 0
- END TRVL_HH
- FROM
- TB_IFSC TI,
- (SELECT
- IFSC_ID,
- LEVL,
- X_CRDN_ARR AS X_CRDN,
- Y_CRDN_ARR AS Y_CRDN,
- X_CRDN_MIN,
- X_CRDN_MAX,
- Y_CRDN_MIN,
- Y_CRDN_MAX
- FROM TB_IFSC_VRTX_ARR) TIVA, TB_IFSC_TRAF TIT,
- (
- SELECT T1.ATRD_ID,T1.ATRD_NM,T1.DRCT_CD,T2.ORD ROAD_ORD,T3.IFSC_ID,T3.ORD IFSC_ORD
- FROM TB_ATRD T1, TB_ATRD_RLTN_ROAD T2, TB_ROAD_RLTN_IFSC T3
- WHERE T1.ATRD_ID = T2.ATRD_ID
- AND T2.ROAD_ID = T3.ROAD_ID
- ) TT
- WHERE TI.IFSC_ID = TIVA.IFSC_ID
- AND TI.IFSC_ID = TIT.IFSC_ID(+)
- AND TI.IFSC_ID = TT.IFSC_ID(+)
- ORDER BY LEVL,DRCT_CD,ROAD_ORD,IFSC_ORD,LINK_ORD
- </select>
- <select id="getLinkVertexArr" resultType="egovframework.vo.RoadVertexArrVO" fetchSize="12000">
- SELECT
- TT.ATRD_ID,
- NVL(TT.ATRD_NM,TL.ROAD_NAME) ATRD_NM,
- DECODE(TT.DRCT_CD,0,'상행','하행') DRCT_CD,
- TT.ROAD_ORD,
- TT.IFSC_ORD,
- TT.LINK_ORD,
- TL.LINK_ID ROAD_ID,
- TL.ROAD_NAME ROAD_NM,
- NVL((SELECT NODE_NAME FROM TB_NODE WHERE TL.F_NODE_ID = NODE_ID),'-') STRT_NM_NODE,
- NVL((SELECT NODE_NAME FROM TB_NODE WHERE TL.T_NODE_ID = NODE_ID),'-') END_NM_NODE,
- 0 SECT_LNGT,
- TLVA.LEVL,
- TLVA.X_CRDN,
- TLVA.Y_CRDN,
- TLVA.X_CRDN_MIN,
- TLVA.X_CRDN_MAX,
- TLVA.Y_CRDN_MIN,
- TLVA.Y_CRDN_MAX,
- CASE WHEN TLT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
- THEN TLT.CMTR_GRAD_CD
- ELSE 'LTC0'
- END CMTR_GRAD_CD,
- CASE WHEN TLT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
- THEN NVL(TLT.SPED,0)
- ELSE 0
- END SPED,
- CASE WHEN TLT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
- THEN NVL(ROUND(TLT.TRVL_HH / 60) + 1,0)
- ELSE 0
- END TRVL_HH
- FROM TB_LINK TL, (SELECT
- LINK_ID,
- LEVL,
- X_CRDN_ARR AS X_CRDN,
- Y_CRDN_ARR AS Y_CRDN,
- X_CRDN_MIN,
- X_CRDN_MAX,
- Y_CRDN_MIN,
- Y_CRDN_MAX
- FROM TB_LINK_VRTX_ARR
- ) 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
- FROM TB_ATRD T1, TB_ATRD_RLTN_ROAD T2, TB_ROAD_RLTN_IFSC T3, TB_IFSC_RLTN_LINK T4
- WHERE T1.ATRD_ID = T2.ATRD_ID
- AND T2.ROAD_ID = T3.ROAD_ID
- AND T3.IFSC_ID = T4.IFSC_ID
- ) TT
- WHERE TL.LINK_ID = TLVA.LINK_ID
- AND TL.LINK_ID = TLT.LINK_ID(+)
- AND TL.LINK_ID = TT.LINK_ID(+)
- AND TLVA.LEVL <![CDATA[ = ]]> 2
- ORDER BY LEVL,DRCT_CD,ROAD_ORD,IFSC_ORD,LINK_ORD
- </select>
- <select id="getVertexArr" resultType="egovframework.vo.RoadVertexArrVO" fetchSize="1000">
- SELECT
- TT.ATRD_ID,
- NVL(TT.ATRD_NM,'-') ATRD_NM,
- DECODE(TT.DRCT_CD,0,'상행','하행') DRCT_CD,
- TT.ROAD_ORD,
- TT.IFSC_ORD,
- TT.LINK_ORD,
- TL.LINK_ID ROAD_ID,
- TL.ROAD_NAME ROAD_NM,
- NVL((SELECT NODE_NAME FROM TB_NODE WHERE TL.F_NODE = NODE_ID),'-') STRT_NM_NODE,
- NVL((SELECT NODE_NAME FROM TB_NODE WHERE TL.T_NODE = NODE_ID),'-') END_NM_NODE,
- 0 SECT_LNGT,
- TLVA.LEVL,
- TLVA.X_CRDN,
- TLVA.Y_CRDN,
- TLVA.X_CRDN_MIN,
- TLVA.X_CRDN_MAX,
- TLVA.Y_CRDN_MIN,
- TLVA.Y_CRDN_MAX,
- CASE WHEN TLT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
- THEN TLT.CMTR_GRAD_CD
- ELSE 'LTC0'
- END CMTR_GRAD_CD,
- CASE WHEN TLT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
- THEN NVL(TLT.SPED,0)
- ELSE 0
- END SPED,
- CASE WHEN TLT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
- THEN NVL(ROUND(TLT.TRVL_HH / 60) + 1,0)
- ELSE 0
- END TRVL_HH
- FROM
- TB_LINK TL,
- (SELECT
- LINK_ID,
- LEVL,
- X_CRDN_ARR AS X_CRDN,
- Y_CRDN_ARR AS Y_CRDN,
- X_CRDN_MIN,
- X_CRDN_MAX,
- Y_CRDN_MIN,
- Y_CRDN_MAX
- FROM TB_LINK_VRTX_ARR) 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
- FROM TB_ATRD T1, TB_ATRD_ROAD_RLTN T2, TB_ROAD_IFSC_RLTN T3, TB_IFSC_LINK_RLTN T4
- WHERE T1.ATRD_ID = T2.ATRD_ID
- AND T2.ROAD_ID = T3.ROAD_ID
- AND T3.IFSC_ID = T4.IFSC_ID
- ) TT
- WHERE TL.LINK_ID = TLVA.LINK_ID
- AND TL.LINK_ID = TLT.LINK_ID(+)
- AND TL.LINK_ID = TT.LINK_ID(+)
- UNION ALL
- SELECT
- TT.ATRD_ID,
- NVL(TT.ATRD_NM,'-') ATRD_NM,
- DECODE(TT.DRCT_CD,0,'상행','하행') DRCT_CD,
- TT.ROAD_ORD,
- TT.IFSC_ORD,
- NULL LINK_ORD,
- TI.IFSC_ID ROAD_ID,
- TI.IFSC_NM ROAD_NM,
- NVL((SELECT NODE_NAME FROM TB_NODE WHERE TI.F_NODE_ID = NODE_ID),'-') STRT_NM_NODE,
- NVL((SELECT NODE_NAME FROM TB_NODE WHERE TI.T_NODE_ID = NODE_ID),'-') END_NM_NODE,
- TI.SECT_LNGT SECT_LNGT,
- TIVA.LEVL,
- TIVA.X_CRDN,
- TIVA.Y_CRDN,
- TIVA.X_CRDN_MIN,
- TIVA.X_CRDN_MAX,
- TIVA.Y_CRDN_MIN,
- TIVA.Y_CRDN_MAX,
- CASE WHEN TIT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
- THEN TIT.CMTR_GRAD_CD
- ELSE 'LTC0'
- END CMTR_GRAD_CD,
- CASE WHEN TIT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
- THEN NVL(TIT.SPED,0)
- ELSE 0
- END SPED,
- CASE WHEN TIT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
- THEN NVL(ROUND(TIT.TRVL_HH / 60) + 1,0)
- ELSE 0
- END TRVL_HH
- FROM
- TB_IFSC TI,
- (SELECT
- IFSC_ID,
- LEVL,
- X_CRDN_ARR AS X_CRDN,
- Y_CRDN_ARR AS Y_CRDN,
- X_CRDN_MIN,
- X_CRDN_MAX,
- Y_CRDN_MIN,
- Y_CRDN_MAX
- FROM TB_IFSC_VRTX_ARR) TIVA, TB_IFSC_TRAF TIT,
- (
- SELECT T1.ATRD_ID,T1.ATRD_NM,T1.DRCT_CD,T2.ORD ROAD_ORD,T3.IFSC_ID,T3.ORD IFSC_ORD
- FROM TB_ATRD T1, TB_ATRD_ROAD_RLTN T2, TB_ROAD_IFSC_RLTN T3
- WHERE T1.ATRD_ID = T2.ATRD_ID
- AND T2.ROAD_ID = T3.ROAD_ID
- ) TT
- WHERE TI.IFSC_ID = TIVA.IFSC_ID
- AND TI.IFSC_ID = TIT.IFSC_ID(+)
- AND TI.IFSC_ID = TT.IFSC_ID(+)
- UNION ALL
- SELECT
- TT.ATRD_ID,
- NVL(TT.ATRD_NM,'-') ATRD_NM,
- DECODE(TT.DRCT_CD,0,'상행','하행') DRCT_CD,
- TT.ROAD_ORD,
- NULL IFSC_ORD,
- NULL LINK_ORD,
- TR.ROAD_ID ROAD_ID,
- TR.ROAD_NAME ROAD_NAME,
- NVL((SELECT NODE_NAME FROM TB_NODE WHERE TR.F_NODE_ID = NODE_ID),'-') STRT_NM_NODE,
- NVL((SELECT NODE_NAME FROM TB_NODE WHERE TR.T_NODE_ID = NODE_ID),'-') END_NM_NODE,
- TR.SECT_LNGT,
- TRVA.LEVL,
- TRVA.X_CRDN,
- TRVA.Y_CRDN,
- TRVA.X_CRDN_MIN,
- TRVA.X_CRDN_MAX,
- TRVA.Y_CRDN_MIN,
- TRVA.Y_CRDN_MAX,
- CASE WHEN TRT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
- THEN TRT.CMTR_GRAD_CD
- ELSE 'LTC0'
- END CMTR_GRAD_CD,
- CASE WHEN TRT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
- THEN NVL(TRT.SPED,0)
- ELSE 0
- END SPED,
- CASE WHEN TRT.PRCN_DT >= TO_CHAR(SYSDATE - 10/24/60,'YYYYMMDDHH24MISS')
- THEN NVL(ROUND(TRT.TRVL_HH / 60) + 1,0)
- ELSE 0
- END TRVL_HH
- FROM
- TB_ROAD TR,
- (SELECT
- ROAD_ID AS ROAD_ID,
- LEVL,
- X_CRDN_ARR AS X_CRDN,
- Y_CRDN_ARR AS Y_CRDN,
- X_CRDN_MIN,
- X_CRDN_MAX,
- Y_CRDN_MIN,
- Y_CRDN_MAX
- FROM TB_ROAD_VRTX_ARR) TRVA, TB_ROAD_TRAF TRT,
- (SELECT T1.ATRD_ID,T1.ATRD_NM,T1.DRCT_CD,T2.ROAD_ID, T2.ORD ROAD_ORD
- FROM TB_ATRD T1, TB_ATRD_ROAD_RLTN T2
- WHERE T1.ATRD_ID = T2.ATRD_ID
- ) TT
- WHERE TR.ROAD_ID = TRVA.ROAD_ID
- AND TR.ROAD_ID = TRT.ROAD_ID(+)
- AND TR.ROAD_ID = TT.ROAD_ID(+)
- ORDER BY LEVL,DRCT_CD,ROAD_ORD,IFSC_ORD,LINK_ORD
- </select>
- <select id="getVmsCtlr" resultType="egovframework.vo.VmsCtlrVO">
- SELECT A.VMS_CTLR_NMBR,
- A.VMS_NM,
- A.X_CRDN,
- A.Y_CRDN,
- NVL(B.CMNC_STTS_CD, 'CMS1') AS CMNC_STTS_CD
- FROM TB_VMS_CTLR A
- LEFT OUTER JOIN TB_VMS_CTLR_STTS B
- ON A.VMS_CTLR_NMBR = B.VMS_CTLR_NMBR
- WHERE A.DEL_YN = 'N'
- ORDER BY A.VMS_NM ASC
- </select>
- <select id="getVmsPhaseImgList" resultType="egovframework.vo.VmsCtlrVO">
- SELECT A.VMS_CTLR_NMBR,
- A.PHASE,
- A.VMS_DSPL_MSG_IMAG,
- A.VMS_DSPL_MSG_TXT
- FROM TB_VMS_DSPL_PRST A,
- (SELECT VMS_CTLR_NMBR, MAX(DSPL_DT) AS DSPL_DT
- FROM TB_VMS_DSPL_PRST
- WHERE DSPL_DT >= TO_CHAR((SYSDATE - 8/1440),'YYYYMMDDHH24MISS')
- GROUP by VMS_CTLR_NMBR) B
- WHERE A.VMS_CTLR_NMBR = B.VMS_CTLR_NMBR
- AND A.DSPL_DT = B.DSPL_DT
- ORDER BY A.VMS_CTLR_NMBR, A.PHASE
- </select>
- <select id="getVmsImgTxt" resultType="egovframework.vo.VmsCtlrVO" parameterType="java.util.HashMap">
- SELECT
- A.VMS_CTLR_NMBR,
- B.VMS_WDTH AS phas_img_width,
- B.VMS_HGHT AS phas_img_height,
- C.PHASE,
- C.VMS_DSPL_MSG_IMAG,
- C.VMS_DSPL_MSG_TXT
- --,NVL((SELECT CMNC_STTS_CD
- -- FROM TB_VMS_CTLR_STTS
- -- WHERE VMS_CTLR_NMBR = A.VMS_CTLR_NMBR
- -- AND UPDT_DT >= TO_CHAR((SYSDATE - 8/1440),'YYYYMMDDHH24MISS')), 'CMS1') AS CMNC_STTS_CD
- FROM TB_VMS_CTLR A
- INNER JOIN TB_VMS_TYPE B
- ON A.VMS_CTLR_NMBR = #{vms_ctlr_nmbr}
- AND A.VMS_TYPE_CD = B.VMS_TYPE_CD
- LEFT OUTER JOIN (SELECT
- VMS_CTLR_NMBR,
- PHASE,
- VMS_DSPL_MSG_IMAG,
- VMS_DSPL_MSG_TXT
- FROM TB_VMS_DSPL_PRST
- WHERE (VMS_CTLR_NMBR, DSPL_DT)
- IN
- (SELECT
- VMS_CTLR_NMBR,
- MAX(DSPL_DT) AS DSPL_DT
- FROM TB_VMS_DSPL_PRST
- WHERE VMS_CTLR_NMBR = #{vms_ctlr_nmbr}
- AND DSPL_DT >= TO_CHAR((SYSDATE - 8/1440),'YYYYMMDDHH24MISS')
- GROUP BY VMS_CTLR_NMBR
- )
- ) C
- ON A.VMS_CTLR_NMBR = C.VMS_CTLR_NMBR
- </select>
- <select id="getWcamCtlr" resultType="egovframework.vo.WcamCtlrVO">
- SELECT WCAM_CTLR_NMBR,
- WCAM_NM,
- WCAM_TYPE_CD,
- NVL(ISTL_LCTN_NM,'-') ISTL_LCTN_NM,
- X_CRDN,
- Y_CRDN,
- STRM_RTSP_ADDR,
- STRM_RTMP_ADDR,
- STRM_HTTP_ADDR
- FROM TB_WCAM_CTLR
- WHERE DEL_YN = 'N'
- </select>
- <select id="getCctvCtlr" resultType="egovframework.vo.CctvCtlrVO">
- SELECT A.CCTV_CTLR_NMBR as cctv_mngm_nmbr,
- A.CCTV_CTLR_ID as cctv_ctlr_id,
- A.CCTV_CTLR_IP as cctv_ctlr_ip,
- A.CCTV_CTLR_PORT as cctv_ctlr_port,
- A.CCTV_CAPT_IP as cctv_capt_ip,
- A.CCTV_CAPT_PORT as cctv_capt_port,
- --A.CCTV_FIBR_IP as cctv_fibr_ip,
- --A.CCTV_ENCD_IP as cctv_encd_ip,
- A.STRM_SVR_IP as strm_svr_ip,
- A.STRM_SVR_PORT as strm_svr_port,
- A.STRM_SESN_NM as strm_sesn_nm,
- A.X_CRDN as x_crdn,
- A.Y_CRDN as y_crdn,
- A.ISTL_LCTN_NM as istl_lctn_nm,
- A.ISTL_LCTN_ADDR as istl_lctn_addr,
- --A.CCTV_CHNL as cctv_chnl,
- A.DEL_YN as del_yn,
- A.LINK_ID as link_id,
- A.NODE_ID as node_id,
- --A.RELY_PORT as rely_port,
- A.STRM_RTSP_ADDR as strm_rtsp_addr,
- --A.STRM_RTMP_ADDR as strm_rtmp_addr,
- A.STRM_HTTP_ADDR as strm_http_addr,
- --A.STRM_STOR_ADDR as strm_stor_addr,
- --A.AREA_CD as area_cd,
- B.CMNC_STTS_CD as cmnc_stts_cd,
- A.WEB_RTC_SVR_PORT as web_rtc_svr_port,
- A.WEB_RTC_SVR_IP as web_rtc_svr_ip,
- A.WEB_RTC_ID as web_rtc_id
- FROM TB_CCTV_CTLR A
- LEFT OUTER JOIN TB_CCTV_CTLR_STTS B
- ON A.CCTV_CTLR_NMBR = B.CCTV_CTLR_NMBR
- WHERE A.DEL_YN = 'N'
- ORDER BY A.ISTL_LCTN_NM ASC
- </select>
- <select id="getOneCctvCtlr" resultType="egovframework.vo.CctvCtlrVO" parameterType="String">
- SELECT
- A.CCTV_CTLR_NMBR as cctv_mngm_nmbr,
- A.CCTV_CTLR_ID as cctv_ctlr_id,
- A.CCTV_CTLR_IP as cctv_ctlr_ip,
- A.CCTV_CTLR_PORT as cctv_ctlr_port,
- A.CCTV_CAPT_IP as cctv_capt_ip,
- A.CCTV_CAPT_PORT as cctv_capt_port,
- --A.CCTV_FIBR_IP as cctv_fibr_ip,
- --A.CCTV_ENCD_IP as cctv_encd_ip,
- A.STRM_SVR_IP as strm_svr_ip,
- A.STRM_SVR_PORT as strm_svr_port,
- A.STRM_SESN_NM as strm_sesn_nm,
- A.X_CRDN as x_crdn,
- A.Y_CRDN as y_crdn,
- A.ISTL_LCTN_NM as istl_lctn_nm,
- A.ISTL_LCTN_ADDR as istl_lctn_addr,
- --A.CCTV_CHNL as cctv_chnl,
- A.DEL_YN as del_yn,
- A.LINK_ID as link_id,
- A.NODE_ID as node_id,
- --A.RELY_PORT as rely_port,
- A.STRM_RTSP_ADDR as strm_rtsp_addr,
- --A.STRM_RTMP_ADDR as strm_rtmp_addr,
- A.STRM_HTTP_ADDR as strm_http_addr,
- --A.STRM_STOR_ADDR as strm_stor_addr,
- --A.AREA_CD as area_cd,
- B.CMNC_STTS_CD as cmnc_stts_cd,
- A.WEB_RTC_SVR_PORT as web_rtc_svr_port,
- A.WEB_RTC_SVR_IP as web_rtc_svr_ip,
- A.WEB_RTC_ID as web_rtc_id
- FROM
- TB_CCTV_CTLR A LEFT OUTER JOIN TB_CCTV_CTLR_STTS B
- ON A.CCTV_CTLR_NMBR = B.CCTV_CTLR_NMBR
- WHERE A.DEL_YN = 'N'
- AND A.CCTV_CTLR_NMBR = #{nmbr}
- ORDER BY ISTL_LCTN_NM ASC
- </select>
-
- <select id="getIncdOcrr" resultType="egovframework.vo.IncdVO">
- SELECT A.INCD_OCRR_ID as incd_ocrr_id,
- A.LINK_ID as link_id,
- SUBSTR(A.INCD_STRT_DT, 0,4) || '년' ||
- SUBSTR(A.INCD_STRT_DT, 5,2) || '월' ||
- SUBSTR(A.INCD_STRT_DT, 7,2) || '일 ' ||
- SUBSTR(A.INCD_STRT_DT, 9,2) || '시' as incd_strt_dt,
- SUBSTR(A.INCD_END_PRAR_DT, 0,4) || '년' ||
- SUBSTR(A.INCD_END_PRAR_DT, 5,2) || '월' ||
- SUBSTR(A.INCD_END_PRAR_DT, 7,2) || '일 ' ||
- SUBSTR(A.INCD_END_PRAR_DT, 9,2) || '시' as incd_end_prar_dt,
- A.OCRR_LCTN_NM AS road_name,
- NVL(TRIM(A.INCD_TITL),'-') AS incd_titl,
- NVL(TRIM(A.INCD_EXPL),'-') AS incd_expl,
- DECODE(A.INCD_TYPE_CLSF_CD,'1','01','2','02','3','03','4','04') AS incd_type_code,
- B.CMMN_CD_KOR_NM as cmmn_cd_kor_nm,
- A.X_CRDN as x_crdn,
- A.Y_CRDN as y_crdn
- FROM TB_INCD_OCRR A, TB_CMMN_CD B
- WHERE A.INCD_PRGR_STEP_CD = 'ISS2'
- AND B.CMMN_CLSF_CD = 'IDTU'
- AND A.INCD_TYPE_CLSF_CD = B.CMMN_CD
- ORDER BY ROAD_NAME
- </select>
-
- <select id="getAtrdNm" resultType="egovframework.vo.AtrdVO">
- <!-- (오라클) WM_CONCAT : 여러행 데이터를 하나의 컬럼으로..
- Oracle 10g에서 사용
- -->
- -- SELECT ATRD_NM as atrd_nm,
- -- WM_CONCAT(ATRD_ID) as atrd_id
- -- FROM TB_ATRD
- -- WHERE DEL_YN = 'N'
- -- GROUP BY ATRD_NM
- <!-- (오라클) LISTAGG : 여러행 데이터를 하나의 컬럼으로..
- Oracle XE 11g 이상에서는 WM_CONCAT() 사용을 못하고,
- 대신에 LISTAGG 사용하면 된다.
- -->
- SELECT ATRD_NM as atrd_nm,
- LISTAGG(ATRD_ID,',') as atrd_id
- FROM TB_ATRD
- WHERE DEL_YN = 'N'
- GROUP BY ATRD_NM ORDER BY ATRD_NM
- <!-- (티베로) AGGR_CONCAT : 여러행 데이터를 하나의 컬럼으로..
- SELECT ATRD_NM as atrd_nm,
- AGGR_CONCAT(ATRD_ID,',') as atrd_id,
- FROM TB_ATRD
- WHERE DEL_YN = 'N'
- GROUP BY ATRD_NM ;
- -->
- </select>
- <select id="getVisitCount" resultType="egovframework.vo.VisitCountVO">
- SELECT SUM(TODAY) AS TODAY,
- SUM(TOTAL) AS TOTAL
- FROM (SELECT NVL(SUM(CONN_CNT), 1) AS TODAY, 0 AS TOTAL
- FROM TB_WWW_CONN_PAGE_STAT_DD t
- WHERE T.STAT_MON = TO_CHAR(SYSDATE, 'YYYYMM')
- AND T.STAT_DD = TO_CHAR(SYSDATE, 'DD')
- AND T.PAGE_ID = 'W1'
- UNION ALL
- SELECT 0 AS TODAY, NVL(SUM(CONN_CNT), 1) AS TOTAL
- FROM TB_WWW_CONN_PAGE_STAT_MN T
- WHERE T.PAGE_ID = 'W1'
- )
- </select>
- <update id="insertUpdateHourLogWeb" parameterType="java.util.HashMap">
- MERGE INTO
- TB_WWW_CONN_PAGE_STAT_HH
- USING
- DUAL
- ON
- (
- STAT_DAY = TO_CHAR (SYSDATE, 'YYYYMMDD')
- AND STAT_HH = TO_CHAR (SYSDATE, 'HH24')
- AND PAGE_ID = (SELECT PAGE_ID FROM TB_WWW_PAGE WHERE PAGE_URL = #{uri})
- )
- WHEN MATCHED THEN
- UPDATE SET
- CONN_CNT = CONN_CNT + 1
- WHEN NOT MATCHED THEN
- INSERT(
- CONN_CNT,
- PAGE_ID,
- STAT_HH,
- STAT_DAY
- )
- VALUES(
- 1,
- (SELECT PAGE_ID FROM TB_WWW_PAGE WHERE PAGE_URL = #{uri}),
- TO_CHAR (SYSDATE, 'HH24'),
- TO_CHAR (SYSDATE, 'YYYYMMDD')
- )
- </update>
- <update id="insertUpdateDateLogWeb" parameterType="java.util.HashMap">
- MERGE INTO
- TB_WWW_CONN_PAGE_STAT_DD
- USING
- DUAL ON
- (
- STAT_MON = TO_CHAR (SYSDATE, 'YYYYMM')
- AND STAT_DD = TO_CHAR (SYSDATE, 'DD')
- AND PAGE_ID = (SELECT PAGE_ID FROM TB_WWW_PAGE WHERE PAGE_URL = #{uri})
- )
- WHEN
- MATCHED THEN
- UPDATE SET CONN_CNT = CONN_CNT + 1
- WHEN
- NOT MATCHED THEN
- INSERT
- (
- CONN_CNT,
- PAGE_ID,
- STAT_DD,
- STAT_MON
- )
- VALUES
- (
- 1,
- (SELECT PAGE_ID FROM TB_WWW_PAGE WHERE PAGE_URL = #{uri}),
- TO_CHAR (SYSDATE, 'DD'),
- TO_CHAR (SYSDATE, 'YYYYMM')
- )
- </update>
- <update id="insertUpdateMonthLogWeb" parameterType="java.util.HashMap">
- MERGE INTO
- TB_WWW_CONN_PAGE_STAT_MN
- USING
- DUAL ON
- (
- STAT_YEAR = TO_CHAR(SYSDATE, 'YYYY')
- AND STAT_MN = TO_CHAR(SYSDATE, 'MM')
- AND PAGE_ID = (SELECT PAGE_ID FROM TB_WWW_PAGE WHERE PAGE_URL = #{uri})
- )
- WHEN
- MATCHED THEN
- UPDATE SET CONN_CNT = CONN_CNT + 1
- WHEN
- NOT MATCHED THEN
- INSERT
- (
- CONN_CNT,
- PAGE_ID,
- STAT_MN,
- STAT_YEAR
- )
- VALUES
- (
- 1,
- (SELECT PAGE_ID FROM TB_WWW_PAGE WHERE PAGE_URL = #{uri}),
- TO_CHAR(SYSDATE, 'MM'),
- TO_CHAR(SYSDATE, 'YYYY')
- )
- </update>
- </mapper>
|