| 123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721 |
- <?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="com.tsi.monitoring.mapper.section.SectionMapper">
- <!-- 센터정보 -->
- <select id="getCenterInfo" resultType="com.tsi.monitoring.vo.CenterVo">
- SELECT A.CENTERID AS CENTER_ID,
- CENTERINFO AS CENTER_INFO,
- IPADDRESS AS IP_ADDRESS,
- NVL(COMMPORT, 0) AS COMM_PORT
- FROM CENTER A
- WHERE CENTERFLAG != 'M'
- ORDER BY CENTER_ID
- </select>
- <!-- 연계센터 정보 -->
- <select id="getMCenterInfo" resultType="com.tsi.monitoring.vo.MCenterVo">
- SELECT MCENTERID AS M_CENTER_ID, CENTER_NAME, IP_ADDRESS
- FROM CENTER_INFO@EXT12LOCDB
- ORDER BY M_CENTER_ID
- </select>
- <!-- 민간센터 정보 -->
- <select id="getMocInfo" resultType="com.tsi.monitoring.vo.CenterVo">
- SELECT A.CENTERID CENTER_ID,
- CENTERINFO CENTER_INFO,
- IPADDRESS IP_ADDRESS,
- NVL(COMMPORT, 0) COMM_PORT
- FROM CENTER_MOCT A
- WHERE CENTERFLAG != 'M'
- ORDER BY CENTER_ID
- </select>
- <!-- 신호연계센터 정보 -->
- <select id="getSigRegionInfo" resultType="com.tsi.monitoring.vo.CenterVo">
- SELECT A.REGION_CD AS CENTER_ID,
- A.REGION_NM AS CENTER_INFO,
- A.IP_ADDRESS AS IP_ADDRESS,
- NVL(A.COMM_PORT, 0) AS COMM_PORT
- FROM TB_REGION_CENTER@SIGDB A
- ORDER BY CENTER_ID
- </select>
- <!-- 신호연계 교차로 정보 -->
- <select id="getSigIntInfo" resultType="com.tsi.monitoring.vo.CenterVo">
- SELECT A.REGION_CD AS CENTER_ID,
- TO_CHAR(A.INT_NO) AS INT_NO,
- A.INT_NM AS INT_NM
- FROM TB_INT@SIGDB A
- ORDER BY CENTER_ID, INT_NM
- </select>
- <select id="getLocalCenterLinkInfo" resultType="com.tsi.monitoring.vo.LocalCenterLinkVo">
- <![CDATA[
- WITH RCV AS (
- SELECT
- MAX(LOGDATE) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS RLOGDATE,
- MAX(DATACNT) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS RDATACNT,
- MAX(INFOTYPE) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS RINFOTYPE,
- CENTERID
- FROM UTIADMIN.center_receive
- WHERE LOGDATE >= TRUNC(SYSDATE - 2)
- AND INFOTYPE = 'R1'
- GROUP BY CENTERID
- ),
- SND AS (
- SELECT
- MAX(LOGDATE) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS SLOGDATE,
- MAX(DATACNT) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS SDATACNT,
- MAX(INFOTYPE) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS SINFOTYPE,
- CENTERID
- FROM UTIADMIN.center_send
- WHERE LOGDATE >= TRUNC(SYSDATE - 2)
- AND INFOTYPE = 'R1'
- GROUP BY CENTERID
- ),
- SND_MOCT AS (
- SELECT
- MAX(LOGDATE) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS MLOGDATE,
- MAX(DATACNT) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS MDATACNT,
- MAX(INFOTYPE) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS MINFOTYPE,
- CENTERID
- FROM UTIADMIN.center_send
- WHERE LOGDATE >= TRUNC(SYSDATE - 2)
- AND INFOTYPE = 'M1'
- GROUP BY CENTERID
- ),
- SIG_CENTER AS (
- SELECT REGION_CD,
- REGION_NM,
- REG_DATE,
- ERR_TIME_GAP
- FROM TB_REGION_CENTER@SIGDB
- ),
- CENTER_CTE AS (
- SELECT * FROM CENTER WHERE CENTERFLAG != 'M'
- ),
- MOCT_CENTER AS (
- SELECT CENTERID, MOCTYN FROM CENTER_MOCT WHERE CENTERFLAG != 'M'
- )
- SELECT DECODE(C.CENTERID, NULL, 'N', 'Y') AS IS_CENTER,
- DECODE(SC.REGION_CD, NULL, 'N', 'Y') AS IS_SIG,
- NVL(C.CENTERID, SC.REGION_CD) AS CENTER_ID,
- NVL(C.CENTERINFO, SC.REGION_NM) AS CENTER_NM,
- C.IPADDRESS AS IP_ADDRESS,
- NVL(C.COMMPORT, 0) AS COMM_PORT,
- TO_CHAR(R.RLOGDATE, 'YYYY-MM-DD HH24:MI:SS') AS R_LOG_DATE,
- 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,
- R.RDATACNT AS R_DATA_CNT,
- R.RINFOTYPE AS R_INFO_TYPE,
- C.RCVYN AS R_YN,
- DECODE(R.RINFOTYPE, 'R1','소통정보','E1','돌발정보','-') AS R_INFO_TYPE_DESC,
- TO_CHAR(S.SLOGDATE, 'YYYY-MM-DD HH24:MI:SS') AS S_LOG_DATE,
- 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,
- S.SDATACNT AS S_DATA_CNT,
- S.SINFOTYPE AS S_INFO_TYPE,
- C.TRAFFICYN AS S_YN,
- DECODE(S.SINFOTYPE, 'R1','소통정보','E1','돌발정보','-') AS S_INFO_TYPE_DESC,
- TO_CHAR(M.MLOGDATE, 'YYYY-MM-DD HH24:MI:SS') AS M_LOG_DATE,
- 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,
- M.MDATACNT AS M_DATA_CNT,
- M.MINFOTYPE AS M_INFO_TYPE,
- MC.MOCTYN AS M_YN,
- '소통정보' AS M_INFO_TYPE_DESC,
- TO_CHAR(SC.REG_DATE, 'YYYY-MM-DD HH24:MI:SS') AS SL_LOG_DATE,
- 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
- FROM CENTER_CTE C
- LEFT OUTER JOIN MOCT_CENTER MC ON C.CENTERID = MC.CENTERID
- LEFT JOIN RCV R ON C.CENTERID = R.CENTERID
- LEFT JOIN SND S ON C.CENTERID = S.CENTERID
- LEFT JOIN SND_MOCT M ON C.CENTERID = M.CENTERID
- FULL OUTER JOIN SIG_CENTER SC ON C.CENTERID = SC.REGION_CD
- ORDER BY CENTER_ID
- ]]>
- </select>
- <!-- <select id="getLocalCenterLinkInfo" resultType="com.tsi.monitoring.vo.LocalCenterLinkVo">-->
- <!-- <![CDATA[-->
- <!-- WITH RCV AS (-->
- <!-- SELECT FROMCENTERID AS CENTERID,-->
- <!-- MAX(LOGDATE) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS RLOGDATE,-->
- <!-- MAX(DATACNT) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS RDATACNT,-->
- <!-- MAX(INFOKIND) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS RINFOTYPE-->
- <!-- FROM RCV_LOG-->
- <!-- GROUP BY FROMCENTERID-->
- <!-- ),-->
- <!-- SND AS (-->
- <!-- SELECT TOCENTERID AS CENTERID,-->
- <!-- MAX(LOGDATE) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS SLOGDATE,-->
- <!-- MAX(DATACNT) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS SDATACNT,-->
- <!-- MAX(INFOKIND) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS SINFOTYPE-->
- <!-- FROM SND_LOG-->
- <!-- GROUP BY TOCENTERID-->
- <!-- ),-->
- <!-- SND_MOCT AS (-->
- <!-- SELECT TOCENTERID AS CENTERID,-->
- <!-- MAX(LOGDATE) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS MLOGDATE,-->
- <!-- MAX(DATACNT) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS MDATACNT,-->
- <!-- MAX(INFOKIND) KEEP (DENSE_RANK FIRST ORDER BY LOGDATE DESC) AS MINFOTYPE-->
- <!-- FROM SND_LOG_MOCT-->
- <!-- GROUP BY TOCENTERID-->
- <!-- ),-->
- <!-- SIG_CENTER AS (-->
- <!-- SELECT REGION_CD,-->
- <!-- REGION_NM,-->
- <!-- REG_DATE,-->
- <!-- ERR_TIME_GAP-->
- <!-- FROM TB_REGION_CENTER@SIGDB-->
- <!-- ),-->
- <!-- CENTER_CTE AS (-->
- <!-- SELECT * FROM CENTER WHERE CENTERFLAG != 'M'-->
- <!-- ),-->
- <!-- MOCT_CENTER AS (-->
- <!-- SELECT CENTERID, MOCTYN FROM CENTER_MOCT WHERE CENTERFLAG != 'M'-->
- <!-- )-->
- <!-- SELECT DECODE(C.CENTERID, NULL, 'N', 'Y') AS IS_CENTER,-->
- <!-- DECODE(SC.REGION_CD, NULL, 'N', 'Y') AS IS_SIG,-->
- <!-- NVL(C.CENTERID, SC.REGION_CD) AS CENTER_ID,-->
- <!-- NVL(C.CENTERINFO, SC.REGION_NM) AS CENTER_NM,-->
- <!-- C.IPADDRESS AS IP_ADDRESS,-->
- <!-- NVL(C.COMMPORT, 0) AS COMM_PORT,-->
- <!-- TO_CHAR(R.RLOGDATE, 'YYYY-MM-DD HH24:MI:SS') AS R_LOG_DATE,-->
- <!-- 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,-->
- <!-- R.RDATACNT AS R_DATA_CNT,-->
- <!-- R.RINFOTYPE AS R_INFO_TYPE,-->
- <!-- C.RCVYN AS R_YN,-->
- <!-- DECODE(R.RINFOTYPE, 'T','소통정보','I','돌발정보','C','통제정보','-') AS R_INFO_TYPE_DESC,-->
- <!-- TO_CHAR(S.SLOGDATE, 'YYYY-MM-DD HH24:MI:SS') AS S_LOG_DATE,-->
- <!-- 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,-->
- <!-- S.SDATACNT AS S_DATA_CNT,-->
- <!-- S.SINFOTYPE AS S_INFO_TYPE,-->
- <!-- C.TRAFFICYN AS S_YN,-->
- <!-- DECODE(S.SINFOTYPE, 'T','소통정보','I','돌발정보','C','통제정보','-') AS S_INFO_TYPE_DESC,-->
- <!-- TO_CHAR(M.MLOGDATE, 'YYYY-MM-DD HH24:MI:SS') AS M_LOG_DATE,-->
- <!-- 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,-->
- <!-- M.MDATACNT AS M_DATA_CNT,-->
- <!-- M.MINFOTYPE AS M_INFO_TYPE,-->
- <!-- MC.MOCTYN AS M_YN,-->
- <!-- DECODE(M.MINFOTYPE, 'T','소통정보','I','돌발정보','C','통제정보','-') AS M_INFO_TYPE_DESC,-->
- <!-- TO_CHAR(SC.REG_DATE, 'YYYY-MM-DD HH24:MI:SS') AS SL_LOG_DATE,-->
- <!-- 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-->
- <!-- FROM CENTER_CTE C-->
- <!-- LEFT OUTER JOIN MOCT_CENTER MC ON C.CENTERID = MC.CENTERID-->
- <!-- LEFT JOIN RCV R ON C.CENTERID = R.CENTERID-->
- <!-- LEFT JOIN SND S ON C.CENTERID = S.CENTERID-->
- <!-- LEFT JOIN SND_MOCT M ON C.CENTERID = M.CENTERID-->
- <!-- FULL OUTER JOIN SIG_CENTER SC ON C.CENTERID = SC.REGION_CD-->
- <!-- ORDER BY CENTER_ID-->
- <!-- ]]>-->
- <!-- </select>-->
- <!-- 센터 민간 송수신 정보 조회 -->
- <select id="getMocSendRecvLog" resultType="com.tsi.monitoring.vo.LogVo">
- SELECT C.CENTERID AS CENTER_ID,
- TO_CHAR(RLOGDATE, 'YYYY-MM-DD HH24:MI:SS') R_LOG_DATE,
- CASE WHEN RLOGDATE IS NULL
- OR RLOGDATE <![CDATA[<]]> SYSDATE - 5/(24*60)
- THEN 1
- ELSE 0
- END R_COMM_STATE,
- NVL(RDATACNT, 0) R_DATA_CNT,
- RINFOTYPE AS R_INFO_TYPE,
- DECODE(RINFOTYPE, 'T', '소통정보', 'I', '돌발정보', 'C', '통제정보', '-') AS R_INFO_TYPE_DESC,
- TO_CHAR(SLOGDATE, 'YYYY-MM-DD HH24:MI:SS') S_LOG_DATE,
- CASE WHEN SLOGDATE IS NULL
- OR SLOGDATE <![CDATA[<]]> SYSDATE - 5/(24*60)
- THEN 1
- ELSE 0
- END S_COMM_STATE,
- NVL(SDATACNT, 0) S_DATA_CNT,
- SINFOTYPE AS S_INFO_TYPE,
- DECODE(SINFOTYPE, 'T', '소통정보', 'I', '돌발정보', 'C', '통제정보', '-') AS S_INFO_TYPE_DESC,
- TO_CHAR(MLOGDATE, 'YYYY-MM-DD HH24:MI:SS') M_LOG_DATE,
- CASE WHEN MLOGDATE IS NULL
- OR MLOGDATE <![CDATA[<]]> SYSDATE - 5/(24*60)
- THEN 1
- ELSE 0
- END M_COMM_STATE,
- NVL(MDATACNT, 0) M_DATA_CNT,
- MINFOTYPE AS M_INFO_TYPE,
- DECODE(MINFOTYPE, 'T', '소통정보', 'I', '돌발정보', 'C', '통제정보', '-') AS M_INFO_TYPE_DESC
- FROM CENTER C,
- (
- SELECT LOGDATE RLOGDATE, FROMCENTERID CENTERID, DATACNT RDATACNT, INFOKIND RINFOTYPE
- FROM (
- SELECT LOGDATE, FROMCENTERID, DATACNT, INFOKIND,
- ROW_NUMBER() OVER(PARTITION BY FROMCENTERID ORDER BY LOGDATE DESC) RRN
- FROM RCV_LOG A1
- )
- WHERE RRN = 1
- ) A,
- (
- SELECT LOGDATE SLOGDATE, TOCENTERID CENTERID, DATACNT SDATACNT, INFOKIND SINFOTYPE
- FROM (
- SELECT TOCENTERID, LOGDATE, DATACNT, INFOKIND,
- ROW_NUMBER() OVER(PARTITION BY TOCENTERID ORDER BY LOGDATE DESC) SRN
- FROM SND_LOG
- )
- WHERE SRN = 1
- ) B,
- (
- SELECT LOGDATE MLOGDATE, TOCENTERID CENTERID, DATACNT MDATACNT, INFOKIND MINFOTYPE
- FROM (
- SELECT TOCENTERID, LOGDATE, DATACNT, INFOKIND,
- ROW_NUMBER() OVER(PARTITION BY TOCENTERID ORDER BY LOGDATE DESC) MRN
- FROM SND_LOG_MOCT
- )
- WHERE MRN = 1
- ) D
- WHERE C.CENTERID = A.CENTERID(+)
- AND C.CENTERID = B.CENTERID(+)
- AND C.CENTERID = D.CENTERID(+)
- AND C.CENTERFLAG != 'M'
- </select>
- <!-- 신호연계 상태정보 -->
- <select id="getSigStatusInfo" resultType="com.tsi.monitoring.vo.StatusVo">
- SELECT A.REGION_CD AS CENTER_ID,
- DECODE(A.REG_DATE, NULL, '1', NVL(A.COMM_STATE, '1')) AS RUN_STATE,
- A.ERR_TIME_GAP AS ERR_TIME_GAP,
- DECODE(A.REG_DATE, NULL, 9000, ROUND((SYSDATE-A.REG_DATE)*24*60*60)) AS REG_TIME_GAP,
- TO_CHAR(A.REG_DATE, 'YYYY-MM-DD HH24:MI:SS') AS LAST_REG_DATE
- FROM TB_REGION_CENTER@SIGDB A
- ORDER BY CENTER_ID
- </select>
- <!-- 신호연계 교차로 상태 정보 조회 -->
- <select id="getSigIntStatusInfo" resultType="com.tsi.monitoring.vo.IntStatusVo">
- SELECT A.REGION_CD AS CENTER_ID,
- TO_CHAR(A.INT_NO) AS INT_NO,
- TO_CHAR(A.COLLCT_DTIME, 'YYYY-MM-DD HH24:MI:SS') AS COLL_DATE,
- NVL(A.COMM_ON_OFF_FLAG, '1') AS COMM_STAT,
- A.CONTRLR_OPER_MODE_CD AS OPER_MODE
- FROM TB_INT_STATUS@SIGDB A
- </select>
- <!-- 센터/민간 로그 정보조회 -->
- <select id="getMogLogInfo" resultType="com.tsi.monitoring.vo.MocLogInfoVo" parameterType="java.util.HashMap">
- SELECT TO_CHAR(LOGDATE, 'YYYY-MM-DD HH24:MI:SS') AS LOG_DATE,
- INFOKIND AS TYPE,
- FROMCENTERID AS CENTER_ID,
- DATACNT AS DATA_CNT,
- DUPKEY AS DUP_KEY,
- 'R' AS RS
- FROM RCV_LOG
- WHERE FROMCENTERID = #{centerId}
- AND LOGDATE >= TRUNC(SYSDATE)
- UNION
- SELECT TO_CHAR(LOGDATE, 'YYYY-MM-DD HH24:MI:SS') AS LOG_DATE,
- INFOKIND AS TYPE,
- TOCENTERID AS CENTER_ID,
- DATACNT AS DATA_CNT,
- '' AS DUP_KEY,
- 'S' AS RS
- FROM SND_LOG
- WHERE TOCENTERID = #{centerId}
- AND LOGDATE >= TRUNC(SYSDATE)
- UNION
- SELECT TO_CHAR(LOGDATE, 'YYYY-MM-DD HH24:MI:SS') AS LOG_DATE,
- INFOKIND AS TYPE,
- TOCENTERID AS CENTER_ID,
- DATACNT AS DATA_CNT,
- '' AS DUP_KEY,
- 'M' AS RS
- FROM SND_LOG_MOCT
- WHERE TOCENTERID = #{centerId}
- AND LOGDATE >= TRUNC(SYSDATE)
- </select>
- <select id="getCenterPreferences" resultType="com.tsi.monitoring.vo.CenterPreferencesVo">
- SELECT CENTERID AS CENTER_ID,
- CENTERINFO AS CENTER_INFO,
- TRAFFICYN AS TRAFFIC_YN,
- INCIDENTYN AS INCIDENT_YN,
- CONTROLYN AS CONTROL_YN
- FROM CENTER
- WHERE CENTERFLAG = 'L'
- ORDER BY CENTERID
- </select>
- <!-- SELECT DECODE(LOG.LOGDATE, NULL, '-', TO_CHAR(LOG.LOGDATE, 'YYYY-MM-DD HH24:MI:SS')) AS LOG_DATE,-->
- <!-- DECODE(LOG.INFOKIND, 'T', '소통정보', 'I', '돌발정보', 'C', '통제정보', '-') AS INFO_KIND,-->
- <!-- LOG.DATACNT DATA_CNT,-->
- <!-- FROM_C.CENTERINFO AS FROM_NM,-->
- <!-- TO_C.CENTERINFO AS TO_NM-->
- <!-- FROM RCV_LOG LOG, CENTER FROM_C, CENTER TO_C-->
- <!-- WHERE LOG.FROMCENTERID = FROM_C.CENTERID-->
- <!-- AND LOG.TOCENTERID = TO_C.CENTERID-->
- <!-- AND LOG.FROMCENTERID = #{centerId}-->
- <!-- AND LOG.LOGDATE >= TRUNC(SYSDATE)-->
- <!-- ORDER BY LOG_DATE DESC-->
- <select id="getRcvHistory" resultType="com.tsi.monitoring.vo.HistoryVo" parameterType="java.util.HashMap">
- <![CDATA[
- WITH DATE_5M AS (
- SELECT TRUNC(SYSDATE) + (LEVEL - 1) * (5/24/60) AS LOG_DATE_5M
- FROM DUAL
- CONNECT BY LEVEL <= 288
- ),
- rcv AS (
- SELECT LOG.LOGDATE AS LOG_DATE,
- DECODE(LOG.INFOTYPE, 'R1', '소통정보', 'E1', '돌발정보', '-') AS INFO_KIND,
- LOG.DATACNT DATA_CNT,
- FROM_C.CENTERINFO AS FROM_NM,
- TO_C.CENTERINFO AS TO_NM
- FROM UTIADMIN.CENTER_RECEIVE LOG, (SELECT CENTERINFO FROM CENTER WHERE CENTERID = 'L00') TO_C, CENTER FROM_C
- WHERE LOG.CENTERID = #{centerId}
- AND LOG.CENTERID = FROM_C.CENTERID
- AND LOG.LOGDATE > TRUNC(SYSDATE)
- )
- SELECT TO_CHAR(t.LOG_DATE_5M, 'YYYY-MM-DD HH24:MI:SS') AS LOG_DATE,
- r.INFO_KIND,
- NVL(SUM(r.DATA_CNT), 0) AS DATA_CNT,
- MAX(r.FROM_NM) AS FROM_NM,
- MAX(r.TO_NM) AS TO_NM
- FROM DATE_5M t
- JOIN rcv r
- ON r.LOG_DATE >= t.LOG_DATE_5M
- AND r.LOG_DATE < t.LOG_DATE_5M + (5/24/60)
- GROUP BY t.LOG_DATE_5M, r.INFO_KIND
- ORDER BY t.LOG_DATE_5M, r.INFO_KIND
- ]]>
- </select>
- <!-- <select id="getSendHistory" resultType="com.tsi.monitoring.vo.HistoryVo" parameterType="java.util.HashMap">-->
- <!-- SELECT DECODE(LOG.LOGDATE, NULL, '-', TO_CHAR(LOG.LOGDATE, 'YYYY-MM-DD HH24:MI:SS')) AS LOG_DATE,-->
- <!-- DECODE(LOG.INFOKIND, 'T', '소통정보', 'I', '돌발정보', 'C', '통제정보', '-') AS INFO_KIND,-->
- <!-- LOG.DATACNT DATA_CNT,-->
- <!-- FROM_C.CENTERINFO AS FROM_NM,-->
- <!-- TO_C.CENTERINFO AS TO_NM-->
- <!-- FROM SND_LOG LOG, CENTER FROM_C, CENTER TO_C-->
- <!-- WHERE LOG.FROMCENTERID = FROM_C.CENTERID-->
- <!-- AND LOG.TOCENTERID = TO_C.CENTERID-->
- <!-- AND LOG.TOCENTERID = #{centerId}-->
- <!-- AND LOG.LOGDATE >= TRUNC(SYSDATE)-->
- <!-- ORDER BY LOG_DATE DESC-->
- <!-- </select>-->
- <select id="getSendHistory" resultType="com.tsi.monitoring.vo.HistoryVo" parameterType="java.util.HashMap">
- <![CDATA[
- WITH DATE_5M AS (
- SELECT TRUNC(SYSDATE) + (LEVEL - 1) * (5/24/60) AS LOG_DATE_5M
- FROM DUAL
- CONNECT BY LEVEL <= 288
- ),
- rcv AS (
- SELECT LOG.LOGDATE AS LOG_DATE,
- DECODE(LOG.INFOTYPE, 'R1', '소통정보', 'E1', '돌발정보', '-') AS INFO_KIND,
- LOG.DATACNT DATA_CNT,
- FROM_C.CENTERINFO AS FROM_NM,
- TO_C.CENTERINFO AS TO_NM
- FROM UTIADMIN.CENTER_SEND LOG, (SELECT CENTERINFO FROM CENTER WHERE CENTERID = 'L00') FROM_C, CENTER TO_C
- WHERE LOG.CENTERID = 'L02'
- AND LOG.CENTERID = TO_C.CENTERID
- AND LOG.LOGDATE > TRUNC(SYSDATE)
- AND LOG.INFOTYPE <> 'M1'
- )
- SELECT TO_CHAR(t.LOG_DATE_5M, 'YYYY-MM-DD HH24:MI:SS') AS LOG_DATE,
- r.INFO_KIND,
- NVL(SUM(r.DATA_CNT), 0) AS DATA_CNT,
- MAX(r.FROM_NM) AS FROM_NM,
- MAX(r.TO_NM) AS TO_NM
- FROM DATE_5M t
- JOIN rcv r
- ON r.LOG_DATE >= t.LOG_DATE_5M
- AND r.LOG_DATE < t.LOG_DATE_5M + (5/24/60)
- GROUP BY t.LOG_DATE_5M, r.INFO_KIND
- ORDER BY t.LOG_DATE_5M, r.INFO_KIND
- ]]>
- </select>
- <!-- SELECT DECODE(LOG.LOGDATE, NULL, '-', TO_CHAR(LOG.LOGDATE, 'YYYY-MM-DD HH24:MI:SS')) AS LOG_DATE,-->
- <!-- DECODE(LOG.INFOKIND, 'T', '소통정보', 'I', '돌발정보', 'C', '통제정보', '-') AS INFO_KIND,-->
- <!-- LOG.DATACNT DATA_CNT,-->
- <!-- FROM_C.CENTERINFO AS FROM_NM,-->
- <!-- TO_C.CENTERINFO AS TO_NM-->
- <!-- FROM SND_LOG_MOCT LOG, CENTER FROM_C, CENTER TO_C-->
- <!-- WHERE LOG.FROMCENTERID = FROM_C.CENTERID-->
- <!-- AND LOG.TOCENTERID = TO_C.CENTERID-->
- <!-- AND LOG.TOCENTERID = #{centerId}-->
- <!-- AND LOG.LOGDATE >= TRUNC(SYSDATE)-->
- <!-- ORDER BY LOG_DATE DESC-->
- <select id="getMoctHistory" resultType="com.tsi.monitoring.vo.HistoryVo" parameterType="java.util.HashMap">
- <![CDATA[
- WITH DATE_5M AS (
- SELECT TRUNC(SYSDATE) + (LEVEL - 1) * (5/24/60) AS LOG_DATE_5M
- FROM DUAL
- CONNECT BY LEVEL <= 288
- ),
- rcv AS (
- SELECT LOG.LOGDATE AS LOG_DATE,
- '소통정보' AS INFO_KIND,
- LOG.DATACNT DATA_CNT,
- FROM_C.CENTERINFO AS FROM_NM,
- TO_C.CENTERINFO AS TO_NM
- FROM UTIADMIN.CENTER_SEND LOG, (SELECT CENTERINFO FROM CENTER WHERE CENTERID = 'L00') FROM_C, CENTER TO_C
- WHERE LOG.CENTERID = 'L02'
- AND LOG.CENTERID = TO_C.CENTERID
- AND LOG.LOGDATE > TRUNC(SYSDATE)
- AND LOG.INFOTYPE = 'M1'
- )
- SELECT TO_CHAR(t.LOG_DATE_5M, 'YYYY-MM-DD HH24:MI:SS') AS LOG_DATE,
- r.INFO_KIND,
- NVL(SUM(r.DATA_CNT), 0) AS DATA_CNT,
- MAX(r.FROM_NM) AS FROM_NM,
- MAX(r.TO_NM) AS TO_NM
- FROM DATE_5M t
- JOIN rcv r
- ON r.LOG_DATE >= t.LOG_DATE_5M
- AND r.LOG_DATE < t.LOG_DATE_5M + (5/24/60)
- GROUP BY t.LOG_DATE_5M, r.INFO_KIND
- ORDER BY t.LOG_DATE_5M, r.INFO_KIND
- ]]>
- </select>
- <select id="getIntStatusHistory" resultType="com.tsi.monitoring.vo.IntStatusVo" parameterType="java.util.HashMap">
- SELECT TIS.REGION_CD AS CENTER_ID,
- TIS.INT_NO,
- TI.INT_NM,
- TIS.COLLCT_DTIME AS COLL_DATE,
- TIS.CONTRLR_OPER_MODE_CD AS OPER_MODE,
- DECODE(TIS.CONTRLR_OPER_MODE_CD,
- '0', 'SCU모드'
- , '1', '비감응 OFFLINE'
- , '2', '감응 OFFLINE'
- , '4', '감응 ONLINE'
- , '5', 'ONLINE'
- , TIS.CONTRLR_OPER_MODE_CD || '_Unknown'
- ) AS OPER_MODE_DESC,
- TIS.COMM_ON_OFF_FLAG AS COMM_STAT
- FROM TB_INT_STATUS@SIGDB TIS
- JOIN TB_INT@SIGDB TI
- ON TIS.REGION_CD = TI.REGION_CD
- AND TIS.INT_NO = TI.INT_NO
- AND TIS.REGION_CD = #{centerId}
- ORDER BY TIS.INT_NO
- </select>
- <select id="getRcvStatistics" parameterType="java.util.HashMap" resultType="com.tsi.monitoring.vo.StatisticsVo">
- <![CDATA[
- WITH HOURS AS (
- SELECT TO_CHAR(LEVEL - 1, 'FM00') AS HH
- FROM DUAL
- CONNECT BY LEVEL <= 24
- ),
- RAW_DATA AS (
- SELECT TO_CHAR(LOGDATE, 'HH24') AS HH,
- LPAD(FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5) * 5, 2, '0') AS MIN_GROUP,
- SUM(DATACNT) AS SUM_DATACNT
- FROM RCV_LOG
- WHERE FROMCENTERID = #{centerId}
- AND LOGDATE >= TRUNC(SYSDATE)
- AND LOGDATE < TRUNC(SYSDATE + 1)
- AND INFOKIND = #{infoKind}
- GROUP BY TO_CHAR(LOGDATE, 'HH24'), FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5)
- ),
- PIVOTED AS (
- SELECT * FROM RAW_DATA
- PIVOT (
- SUM(SUM_DATACNT)
- FOR MIN_GROUP IN (
- '00' AS M00, '05' AS M05, '10' AS M10, '15' AS M15,
- '20' AS M20, '25' AS M25, '30' AS M30, '35' AS M35,
- '40' AS M40, '45' AS M45, '50' AS M50, '55' AS M55
- )
- )
- )
- SELECT H.HH,
- NVL(P.M00, 0) AS M00,
- NVL(P.M05, 0) AS M05,
- NVL(P.M10, 0) AS M10,
- NVL(P.M15, 0) AS M15,
- NVL(P.M20, 0) AS M20,
- NVL(P.M25, 0) AS M25,
- NVL(P.M30, 0) AS M30,
- NVL(P.M35, 0) AS M35,
- NVL(P.M40, 0) AS M40,
- NVL(P.M45, 0) AS M45,
- NVL(P.M50, 0) AS M50,
- NVL(P.M55, 0) AS M55,
- NVL(P.M00, 0) + NVL(P.M05, 0) + NVL(P.M10, 0) + NVL(P.M15, 0) + NVL(P.M20, 0) + NVL(P.M25, 0) +
- 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
- FROM HOURS H
- LEFT JOIN PIVOTED P ON H.HH = P.HH
- ORDER BY H.HH
- ]]>
- </select>
- <select id="getSndStatistics" parameterType="java.util.HashMap" resultType="com.tsi.monitoring.vo.StatisticsVo">
- <![CDATA[
- WITH HOURS AS (
- SELECT TO_CHAR(LEVEL - 1, 'FM00') AS HH
- FROM DUAL
- CONNECT BY LEVEL <= 24
- ),
- RAW_DATA AS (
- SELECT TO_CHAR(LOGDATE, 'HH24') AS HH,
- LPAD(FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5) * 5, 2, '0') AS MIN_GROUP,
- SUM(DATACNT) AS SUM_DATACNT
- FROM SND_LOG
- WHERE TOCENTERID = #{centerId}
- AND LOGDATE >= TRUNC(SYSDATE)
- AND LOGDATE < TRUNC(SYSDATE + 1)
- AND INFOKIND = #{infoKind}
- GROUP BY TO_CHAR(LOGDATE, 'HH24'), FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5)
- ),
- PIVOTED AS (
- SELECT * FROM RAW_DATA
- PIVOT (
- SUM(SUM_DATACNT)
- FOR MIN_GROUP IN (
- '00' AS M00, '05' AS M05, '10' AS M10, '15' AS M15,
- '20' AS M20, '25' AS M25, '30' AS M30, '35' AS M35,
- '40' AS M40, '45' AS M45, '50' AS M50, '55' AS M55
- )
- )
- )
- SELECT H.HH,
- NVL(P.M00, 0) AS M00,
- NVL(P.M05, 0) AS M05,
- NVL(P.M10, 0) AS M10,
- NVL(P.M15, 0) AS M15,
- NVL(P.M20, 0) AS M20,
- NVL(P.M25, 0) AS M25,
- NVL(P.M30, 0) AS M30,
- NVL(P.M35, 0) AS M35,
- NVL(P.M40, 0) AS M40,
- NVL(P.M45, 0) AS M45,
- NVL(P.M50, 0) AS M50,
- NVL(P.M55, 0) AS M55,
- NVL(P.M00, 0) + NVL(P.M05, 0) + NVL(P.M10, 0) + NVL(P.M15, 0) + NVL(P.M20, 0) + NVL(P.M25, 0) +
- 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
- FROM HOURS H
- LEFT JOIN PIVOTED P ON H.HH = P.HH
- ORDER BY H.HH
- ]]>
- </select>
- <select id="getSndMoctStatistics" parameterType="java.lang.String" resultType="com.tsi.monitoring.vo.StatisticsVo">
- <![CDATA[
- WITH HOURS AS (
- SELECT TO_CHAR(LEVEL - 1, 'FM00') AS HH
- FROM DUAL
- CONNECT BY LEVEL <= 24
- ),
- RAW_DATA AS (
- SELECT TO_CHAR(LOGDATE, 'HH24') AS HH,
- LPAD(FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5) * 5, 2, '0') AS MIN_GROUP,
- SUM(DATACNT) AS SUM_DATACNT
- FROM SND_LOG_MOCT
- WHERE TOCENTERID = #{centerId}
- AND LOGDATE >= TRUNC(SYSDATE)
- AND LOGDATE < TRUNC(SYSDATE + 1)
- GROUP BY TO_CHAR(LOGDATE, 'HH24'), FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5)
- ),
- PIVOTED AS (
- SELECT * FROM RAW_DATA
- PIVOT (
- SUM(SUM_DATACNT)
- FOR MIN_GROUP IN (
- '00' AS M00, '05' AS M05, '10' AS M10, '15' AS M15,
- '20' AS M20, '25' AS M25, '30' AS M30, '35' AS M35,
- '40' AS M40, '45' AS M45, '50' AS M50, '55' AS M55
- )
- )
- )
- SELECT H.HH,
- NVL(P.M00, 0) AS M00,
- NVL(P.M05, 0) AS M05,
- NVL(P.M10, 0) AS M10,
- NVL(P.M15, 0) AS M15,
- NVL(P.M20, 0) AS M20,
- NVL(P.M25, 0) AS M25,
- NVL(P.M30, 0) AS M30,
- NVL(P.M35, 0) AS M35,
- NVL(P.M40, 0) AS M40,
- NVL(P.M45, 0) AS M45,
- NVL(P.M50, 0) AS M50,
- NVL(P.M55, 0) AS M55,
- NVL(P.M00, 0) + NVL(P.M05, 0) + NVL(P.M10, 0) + NVL(P.M15, 0) + NVL(P.M20, 0) + NVL(P.M25, 0) +
- 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
- FROM HOURS H
- LEFT JOIN PIVOTED P ON H.HH = P.HH
- ORDER BY H.HH
- ]]>
- </select>
- <select id="getPeriodCenterRcvSendStatistics" parameterType="java.util.HashMap" resultType="com.tsi.monitoring.vo.PeriodCenterRcvSendStatisticsVo">
- <![CDATA[
- WITH
- params AS (
- SELECT TO_DATE(CONCAT(#{searchDt}, ' 00:00:00'), 'YYYY-MM-DD HH24:MI:SS') AS start_dt,
- TO_DATE(CONCAT(#{searchDt}, ' 23:55:00'), 'YYYY-MM-DD HH24:MI:SS') AS end_dt
- FROM dual
- ),
- slots AS (
- SELECT params.start_dt + (LEVEL - 1) * (5/1440) AS slot_dt
- FROM params
- CONNECT BY params.start_dt + (LEVEL - 1) * (5/1440) <= params.end_dt
- ),
- logs_rcv AS (
- SELECT * FROM RCV_LOG WHERE FROMCENTERID = #{centerId}
- ),
- logs_snd AS (
- SELECT * FROM SND_LOG WHERE TOCENTERID = #{centerId}
- ),
- logs_moct AS (
- SELECT * FROM SND_LOG_MOCT WHERE TOCENTERID = #{centerId}
- ),
- agg_rcv AS (
- SELECT TRUNC(LOGDATE, 'HH24') + FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5) * (5/1440) AS slot_dt,
- SUM(CASE WHEN INFOKIND = 'T' THEN DATACNT ELSE 0 END) AS T_CNT,
- SUM(CASE WHEN INFOKIND = 'I' THEN DATACNT ELSE 0 END) AS I_CNT
- FROM logs_rcv, params
- WHERE LOGDATE BETWEEN params.start_dt AND params.end_dt + (5/1440)
- GROUP BY TRUNC(LOGDATE, 'HH24') + FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5) * (5/1440)
- ),
- agg_snd AS (
- SELECT TRUNC(LOGDATE, 'HH24') + FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5) * (5/1440) AS slot_dt,
- SUM(CASE WHEN INFOKIND = 'T' THEN DATACNT ELSE 0 END) AS T_CNT,
- SUM(CASE WHEN INFOKIND = 'I' THEN DATACNT ELSE 0 END) AS I_CNT
- FROM logs_snd, params
- WHERE LOGDATE BETWEEN params.start_dt AND params.end_dt + (5/1440)
- GROUP BY TRUNC(LOGDATE, 'HH24') + FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5) * (5/1440)
- ),
- agg_moct AS (
- SELECT TRUNC(LOGDATE, 'HH24') + FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5) * (5/1440) AS slot_dt,
- SUM(NVL(DATACNT, 0)) AS CNT
- FROM logs_moct, params
- WHERE LOGDATE BETWEEN params.start_dt AND params.end_dt + (5/1440)
- GROUP BY TRUNC(LOGDATE, 'HH24') + FLOOR(TO_NUMBER(TO_CHAR(LOGDATE, 'MI')) / 5) * (5/1440)
- ),
- rcv_final AS (
- SELECT s.slot_dt,
- NVL(r.T_CNT, 0) AS R_T_CNT,
- NVL(r.I_CNT, 0) AS R_I_CNT
- FROM slots s
- LEFT JOIN agg_rcv r ON s.slot_dt = r.slot_dt
- ),
- snd_final AS (
- SELECT s.slot_dt,
- NVL(snd.T_CNT, 0) AS S_T_CNT,
- NVL(snd.I_CNT, 0) AS S_I_CNT
- FROM slots s
- LEFT JOIN agg_snd snd ON s.slot_dt = snd.slot_dt
- ),
- moct_final AS (
- SELECT s.slot_dt, NVL(m.CNT, 0) AS S_M_CNT
- FROM slots s
- LEFT JOIN agg_moct m ON s.slot_dt = m.slot_dt
- )
- SELECT TO_CHAR(r.slot_dt, 'YYYY-MM-DD HH24:MI:SS') AS LOG_DATE,
- r.R_T_CNT,
- r.R_I_CNT,
- s.S_T_CNT,
- s.S_I_CNT,
- m.S_M_CNT
- FROM rcv_final r
- JOIN snd_final s ON r.slot_dt = s.slot_dt
- JOIN moct_final m ON r.slot_dt = m.slot_dt
- ORDER BY r.slot_dt
- ]]>
- </select>
- </mapper>
|