<?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.zc.business.mapper.DcTrafficIncidentsMapper">


    <select id="getTrafficIncidentsProcessing" resultType="Integer">
        select count(*) from dc_event
        where event_type = '1' and event_state != '2' and date_format(start_time,'%y%m%d') = date_format(now(),'%y%m%d')
    </select>


    <select id="getTrafficIncidentsAll" resultType="Integer">
        select count(*) from dc_event
        where event_type = '1' and date_format(start_time,'%y%m%d') = date_format(now(),'%y%m%d')
    </select>

    <select id="getConstructionNum" resultType="java.lang.Integer">
        select count(*) from dc_event
        where event_type = '7' and event_state != '2'
    </select>

    <select id="getEventListByType" resultType="java.util.Map" parameterType="String">
        select t1.id,t1.stake_mark stakeMark,t1.direction, t2.longitude,t2.latitude
        from dc_event t1 left join dc_stake_mark t2 on t1.stake_mark = t2.stake_mark and t1.direction = t2.direction
        where t1.event_type = #{eventType} and t1.event_state != '2'
    </select>

    <select id="selectTrafficIncidentsDay" resultType="Long">
        select count(*) from dc_event
        where date_format(start_time,'%y%m%d') = date_format(now(),'%y%m%d')
    </select>

    <select id="selectTrafficIncidentsWeek" resultType="Long">
        select count(*) from dc_event
        where YEARWEEK(start_time, 1) = YEARWEEK(now(), 1)
    </select>

    <select id="selectTrafficIncidentsMonth" resultType="Long">
        select count(*) from dc_event
        where date_format(start_time,'%y%m') = date_format(now(),'%y%m')
    </select>

    <select id="selectTrafficIncidentsYear" resultType="Long">
        select count(*) from dc_event
        where date_format(start_time,'%y') = date_format(now(),'%y')
    </select>

    <select id="selectTrafficIncidentsAllProcessing" resultType="java.lang.Long">
        select count(*) from dc_event
        where event_state != '2'
    </select>

    <select id="selectEventTypeList" resultType="java.util.Map">
        select event_type eventType,event_name eventName from dc_event_type
    </select>

    <select id="selectStatusCountByEventType" resultType="java.util.Map" parameterType="String">
        select event_state eventState,count(*) num from dc_event
        where event_type = #{eventType} and date_format(start_time,'%y%m%d') = date_format(now(),'%y%m%d')
        group by event_state
    </select>

    <select id="getEventTypeRatio" resultType="java.util.Map">
        select t1.event_type eventType,t1.event_name eventName,IFNULL(num,0) num
        FROM dc_event_type t1
        left join
            (select event_type eventType, count(*) num
            from dc_event
            where date_format(start_time,'%y%m%d') = date_format(now(),'%y%m%d')
            group by event_type) t2
        on t1.event_type = t2.eventType
    </select>

    <select id="getEventSourceRatio" resultType="java.util.Map">
        select t1.eventSource,t1.eventSourceName,IFNULL(t2.num,0) num from
            (select '1' as eventSource,'96659' as eventSourceName
            UNION ALL select '2' as eventSource,'交警转接' as eventSourceName
            UNION ALL select '3' as eventSource,'道路巡查' as eventSourceName
            UNION ALL select '4' as eventSource,'视频巡查' as eventSourceName
            UNION ALL select '5' as eventSource,'视频AI' as eventSourceName
            UNION ALL select '6' as eventSource,'一键救援' as eventSourceName
            UNION ALL select '7' as eventSource,'其他' as eventSourceName) t1
        LEFT JOIN
            (select event_source eventSource,count(*) num
            from dc_event
            where date_format(start_time,'%y%m%d') = date_format(now(),'%y%m%d')
            group by event_source) t2
        on t1.eventSource = t2.eventSource
    </select>

    <select id="getTrafficTrend" resultType="java.util.Map">
        SELECT t1.hours, ifnull(t2.num, 0) num
        FROM
            (SELECT 0 hours
            UNION ALL SELECT 1 hours
            UNION ALL SELECT 2 hours
            UNION ALL SELECT 3 hours
            UNION ALL SELECT 4 hours
            UNION ALL SELECT 5 hours
            UNION ALL SELECT 6 hours
            UNION ALL SELECT 7 hours
            UNION ALL SELECT 8 hours
            UNION ALL SELECT 9 hours
            UNION ALL SELECT 10 hours
            UNION ALL SELECT 11 hours
            UNION ALL SELECT 12 hours
            UNION ALL SELECT 13 hours
            UNION ALL SELECT 14 hours
            UNION ALL SELECT 15 hours
            UNION ALL SELECT 16 hours
            UNION ALL SELECT 17 hours
            UNION ALL SELECT 18 hours
            UNION ALL SELECT 19 hours
            UNION ALL SELECT 20 hours
            UNION ALL SELECT 21 hours
            UNION ALL SELECT 22 hours
            UNION ALL SELECT 23 hours
            ) t1
        LEFT JOIN
            (SELECT
                hour(start_time) hours,
                count(*) num
            FROM dc_event
            WHERE date_format(start_time, '%Y-%m-%d') = current_date
            GROUP BY date_format(start_time, '%Y%m%d-%H'), hours
            ) t2
        ON t1.hours = t2.hours
        where HOUR(now()) >= t1.hours
        ORDER BY hours
    </select>

    <select id="getPerceptionTrend" resultType="java.util.Map">
        SELECT t1.hours, ifnull(t2.num, 0) num
        FROM
            (SELECT 0 hours
            UNION ALL SELECT 1 hours
            UNION ALL SELECT 2 hours
            UNION ALL SELECT 3 hours
            UNION ALL SELECT 4 hours
            UNION ALL SELECT 5 hours
            UNION ALL SELECT 6 hours
            UNION ALL SELECT 7 hours
            UNION ALL SELECT 8 hours
            UNION ALL SELECT 9 hours
            UNION ALL SELECT 10 hours
            UNION ALL SELECT 11 hours
            UNION ALL SELECT 12 hours
            UNION ALL SELECT 13 hours
            UNION ALL SELECT 14 hours
            UNION ALL SELECT 15 hours
            UNION ALL SELECT 16 hours
            UNION ALL SELECT 17 hours
            UNION ALL SELECT 18 hours
            UNION ALL SELECT 19 hours
            UNION ALL SELECT 20 hours
            UNION ALL SELECT 21 hours
            UNION ALL SELECT 22 hours
            UNION ALL SELECT 23 hours
            ) t1
        LEFT JOIN
            (SELECT
                hour(create_time) hours,count(*) num
            FROM dc_warning
            WHERE date_format(create_time, '%Y-%m-%d') = current_date
            GROUP BY date_format(create_time, '%Y%m%d-%H'), hours) t2
        ON t1.hours = t2.hours
        where HOUR(now()) >= t1.hours
        ORDER BY hours
    </select>

    <select id="getAccidentVehicleAnalysis" resultType="java.util.Map">
        select t1.id,
            case when ISNULL(t1.end_time) then TIMESTAMPDIFF(MINUTE,t1.start_time,now()) else TIMESTAMPDIFF(MINUTE,t1.start_time,t1.end_time) end minuteTime,
            ifNull(t2.small_car,0) smallCar,
            ifNull(t2.trucks,0) trucks,
            ifNull(t2.buses,0) buses,
            ifNull(t2.tankers,0) tankers
        from dc_event t1
        left join dc_event_vehicle_accident t2 on t1.id = t2.id
        where t1.event_type = '1' and t1.direction = #{direction}
            <if test="type != null and type == '1'.toString">
                and DATE_FORMAT(t1.start_time,'%Y%m%d') = DATE_FORMAT(#{startTime},'%Y%m%d')
            </if>
            <if test="type != null and type == '2'.toString">
                and DATE_FORMAT(t1.start_time,'%Y%m') = DATE_FORMAT(#{startTime},'%Y%m')
            </if>
            <if test="type != null and type == '3'.toString">
                and YEAR(t1.start_time) = YEAR(#{startTime}) and QUARTER(t1.start_time) = QUARTER(#{startTime})
            </if>
            <if test="type != null and type == '4'.toString">
                and YEAR(t1.start_time) = YEAR(#{startTime})
            </if>
    </select>

    <select id="selectTollStationAnalysis" resultType="java.util.Map">
        select t3.control_cause controlCause,t3.cause_type causeType,controlCauseName,causeTypeName,IFNULL(t4.num,0) num,ifNull(t4.minuteTime,0) minuteTime
        from
            (select 1 control_cause,'' cause_type,'车流量大' controlCauseName,'' causeTypeName
            UNION ALL select 2 control_cause,'' cause_type,'交通事故' controlCauseName,'' causeTypeName
            UNION ALL select 3 control_cause,'3-1' cause_type,'恶劣天气' controlCauseName,'雨' causeTypeName
            UNION ALL select 3 control_cause,'3-2' cause_type,'恶劣天气' controlCauseName,'雪' causeTypeName
            UNION ALL select 3 control_cause,'3-3' cause_type,'恶劣天气' controlCauseName,'雾' causeTypeName
            UNION ALL select 3 control_cause,'3-4' cause_type,'恶劣天气' controlCauseName,'道路积水' causeTypeName
            UNION ALL select 3 control_cause,'3-5' cause_type,'恶劣天气' controlCauseName,'道路湿滑' causeTypeName
            UNION ALL select 3 control_cause,'3-6' cause_type,'恶劣天气' controlCauseName,'道路结冰' causeTypeName
            UNION ALL select 3 control_cause,'3-7' cause_type,'恶劣天气' controlCauseName,'沙尘暴' causeTypeName
            UNION ALL select 4 control_cause,'' cause_type,'施工' controlCauseName,'' causeTypeName
            UNION ALL select 5 control_cause,'' cause_type,'警备任务' controlCauseName,'' causeTypeName
            UNION ALL select 6 control_cause,'' cause_type,'其他' controlCauseName,'' causeTypeName) t3
        LEFT JOIN
            (select t2.control_type,t2.control_cause,t2.cause_type,count(*) num,sum(
                case when date_format(#{startTime},'%Y-%m-%d %H:%i:%s') >= date_format(t1.start_time,'%Y-%m-%d %H:%i:%s')
                    and  (DATE_FORMAT(t1.end_time,'%Y-%m-%d %H:%i:%s') >= DATE_FORMAT(#{endTime},'%Y-%m-%d %H:%i:%s') or ISNULL(t1.end_time))
                then TIMESTAMPDIFF(MINUTE,t1.start_time,now())
                when date_format(#{startTime},'%Y-%m-%d %H:%i:%s') >= date_format(t1.start_time,'%Y-%m-%d %H:%i:%s')
                    and  DATE_FORMAT(t1.end_time,'%Y-%m-%d %H:%i:%s') &lt;= DATE_FORMAT(#{endTime},'%Y-%m-%d %H:%i:%s')
                then TIMESTAMPDIFF(MINUTE,#{startTime},t1.end_time)
                when date_format(#{startTime},'%Y-%m-%d %H:%i:%s') &lt;= date_format(t1.start_time,'%Y-%m-%d %H:%i:%s')
                    and  (DATE_FORMAT(t1.end_time,'%Y-%m-%d %H:%i:%s') >= DATE_FORMAT(#{endTime},'%Y-%m-%d %H:%i:%s') or ISNULL(t1.end_time))
                then TIMESTAMPDIFF(MINUTE,t1.start_time,#{endTime})
                when date_format(#{startTime},'%Y-%m-%d %H:%i:%s') &lt;= date_format(t1.start_time,'%Y-%m-%d %H:%i:%s')
                    and  DATE_FORMAT(t1.end_time,'%Y-%m-%d %H:%i:%s') &lt;= DATE_FORMAT(#{endTime},'%Y-%m-%d %H:%i:%s')
                then TIMESTAMPDIFF(MINUTE,t1.start_time,t1.end_time)
                else 0 end) minuteTime
            from dc_event t1 LEFT JOIN dc_event_traffic_control t2 on t1.id = t2.id
            <where>
                t1.event_type = '3' and t1.event_subclass = '3-2'
                <if test="facilityIdList != null and facilityIdList.length > 0">
                    AND t2.facility_id in
                    <foreach collection="facilityIdList" item="facilityId" open="(" separator="," close=")">
                        #{facilityId}
                    </foreach>
                </if>
                and  date_format(t1.start_time,'%Y-%m-%d %H:%i:%s') &lt;= date_format(#{endTime},'%Y-%m-%d %H:%i:%s')
                and (date_format(t1.end_time,'%Y-%m-%d %H:%i:%s') > date_format(#{startTime},'%Y-%m-%d %H:%i:%s') or ISNULL(t1.end_time))
            </where>
            GROUP BY t2.control_cause,t2.cause_type) t4
        on t3.control_cause = t4.control_cause and t3.cause_type = t4.cause_type
        ORDER BY t3.control_cause, t3.cause_type
    </select>

    <select id="selectTollStationAnalysisByFacility"  resultType="java.util.Map">
        select
            t2.facility_id facilityId,t3.facility_name facilityName,classify,
            SUM(case when t2.classify = '6' then 1 else 0 end) facilityClose,
            SUM(case when t2.classify = '7' then 1 else 0 end) facilityRestriction,
            SUM(case when t2.classify = '9' then 1 else 0 end) facilityInterval
        from dc_event t1
        LEFT JOIN dc_event_traffic_control t2 on t1.id = t2.id
        LEFT JOIN dc_facility t3 on t3.id = t2.facility_id
        <where>
            t1.event_type = '3' and t1.event_subclass = '3-2'
            and  date_format(t1.start_time,'%Y-%m-%d %H:%i:%s') &lt;= date_format(#{endTime},'%Y-%m-%d %H:%i:%s')
            and (date_format(t1.end_time,'%Y-%m-%d %H:%i:%s') > date_format(#{startTime},'%Y-%m-%d %H:%i:%s') or ISNULL(t1.end_time))
            and t2.classify in ('6','7','9')
            <if test="facilityIdList != null and facilityIdList.length > 0">
                AND t2.facility_id in
                <foreach collection="facilityIdList" item="facilityId" open="(" separator="," close=")">
                    #{facilityId}
                </foreach>
            </if>
        </where>
        GROUP BY t2.facility_id
    </select>

    <select id="getTollStationAnalysis" resultType="java.util.Map">
        select t3.facility_name facilityName,ifNull(t4.trafficClose,0) trafficClose, ifnull(t4.trafficRestriction,0) trafficRestriction
        from
            (select * from dc_facility where facility_type = '1' ) t3
        LEFT JOIN
            (select t2.facility_id facilityId,sum(case when t2.control_type = '1' then 1 else 0 end) trafficClose,
                sum(case when t2.control_type = '2' then 1 else 0 end) trafficRestriction
            from dc_event t1 left join dc_event_traffic_control t2 on t1.id = t2.id
                where (DATE_FORMAT(t1.start_time,'%Y-%m') = DATE_FORMAT(now(),'%Y-%m') or DATE_FORMAT(t1.end_time,'%Y-%m') = DATE_FORMAT(now(),'%Y-%m') or ISNULL(t1.end_time))
                and t1.event_type = '3' and t1.event_subclass = '3-2'
            GROUP BY t2.facility_id) t4
        on t3.id = t4.facilityId
    </select>

    <select id="selectRoadSectionAnalysis" resultType="java.util.Map">

        select t3.section_name,t3.mileage,IFNULL(t4.num,0) num,IFNULL(t5.lastNum,0) lastNum,
            ROUND(IFNULL( t4.num / t3.mileage * 100, 0 ),2) avgNum
        from
            (select * from dc_road_section) t3
        LEFT JOIN
            (select t2.section_id, count(*) num
            from dc_event t1
            left join dc_stake_mark t2 on t1.stake_mark = t2.stake_mark and t1.direction = t2.direction
            where
                t1.event_type = '1' and t1.direction = #{direction}
                <if test="type != null and type == '1'.toString">
                    and DATE_FORMAT(t1.start_time,'%Y%m%d') = DATE_FORMAT(#{startTime},'%Y%m%d')
                </if>
                <if test="type != null and type == '2'.toString">
                    and DATE_FORMAT(t1.start_time,'%Y%m') = DATE_FORMAT(#{startTime},'%Y%m')
                </if>
                <if test="type != null and type == '3'.toString">
                    and YEAR(t1.start_time) = YEAR(#{startTime}) and QUARTER(t1.start_time) = QUARTER(#{startTime})
                </if>
                <if test="type != null and type == '4'.toString">
                    and YEAR(t1.start_time) = YEAR(#{startTime})
                </if>
            GROUP BY t2.section_id) t4
        on t3.id = t4.section_id
        LEFT JOIN
            (select t2.section_id, count(*) lastNum
            from dc_event t1
            left join dc_stake_mark t2 on t1.stake_mark = t2.stake_mark and t1.direction = t2.direction
            where
                t1.event_type = '1' and t1.direction = #{direction}
                <if test="type != null and type == '1'.toString">
                    and DATE_FORMAT(t1.start_time,'%Y%m%d') = DATE_FORMAT(DATE_SUB(#{startTime},INTERVAL 1 DAY),'%Y%m%d')
                </if>
                <if test="type != null and type == '2'.toString">
                    and DATE_FORMAT(t1.start_time,'%Y%m') = DATE_FORMAT(DATE_SUB(#{startTime},INTERVAL 1 MONTH),'%Y%m')
                </if>
                <if test="type != null and type == '3'.toString">
                    and YEAR(t1.start_time) = YEAR(DATE_SUB(#{startTime},INTERVAL 1 QUARTER)) and QUARTER(t1.start_time) = QUARTER(DATE_SUB(#{startTime},INTERVAL 1 QUARTER))
                </if>
                <if test="type != null and type == '4'.toString">
                    and YEAR(t1.start_time) = YEAR(DATE_SUB(#{startTime},INTERVAL 1 YEAR))
                </if>
            GROUP BY t2.section_id) t5
        on t3.id = t5.section_id
    </select>

    <select id="selectEventTypeAnalysis" resultType="java.util.Map">

        select t1.eventSubclass,t1.eventSubclassName,IFNULL(t2.num,0) num,IFNULL(t3.num,0) lastNum,
            IFNULL(t2.minuteTime,0) minuteTime,ROUND(IFNULL(t2.minuteTime/t2.num,0)) avgTime,
            IFNULL(t3.minuteTime,0) lastMinuteTime,ROUND(IFNULL(t3.minuteTime/t3.num,0)) lastAvgTime
        from
            (select '1-1' eventSubclass, '追尾' eventSubclassName
            UNION ALL select '1-2' eventSubclass, '侧翻' eventSubclassName
            UNION ALL select '1-3' eventSubclass, '撞护栏' eventSubclassName
            UNION ALL select '1-4' eventSubclass, '自燃' eventSubclassName
            UNION ALL select '1-5' eventSubclass, '其他事故' eventSubclassName) t1
        LEFT JOIN
            (select event_subclass, count(*) num ,
                sum(case when ISNULL(end_time)
                    then TIMESTAMPDIFF(MINUTE,start_time,now())
                    else TIMESTAMPDIFF(MINUTE,start_time,end_time)
                    end) minuteTime
             from dc_event
             where event_type = '1' and direction = #{direction}
                <if test="type != null and type == '1'.toString">
                    and DATE_FORMAT(start_time,'%Y%m%d') = DATE_FORMAT(#{startTime},'%Y%m%d')
                </if>
                <if test="type != null and type == '2'.toString">
                    and DATE_FORMAT(start_time,'%Y%m') = DATE_FORMAT(#{startTime},'%Y%m')
                </if>
                <if test="type != null and type == '3'.toString">
                    and YEAR(start_time) = YEAR(#{startTime}) and QUARTER(start_time) = QUARTER(#{startTime})
                </if>
                <if test="type != null and type == '4'.toString">
                    and YEAR(start_time) = YEAR(#{startTime})
                </if>
            group by event_subclass) t2
        on t1.eventSubclass = t2.event_subclass
        LEFT JOIN
            (select event_subclass, count(*) num ,
                sum(case when ISNULL(end_time)
                    then TIMESTAMPDIFF(MINUTE,start_time,now())
                    else TIMESTAMPDIFF(MINUTE,start_time,end_time)
                    end) minuteTime
             from dc_event
             where event_type = '1' and direction = #{direction}
                <if test="type != null and type == '1'.toString">
                    and DATE_FORMAT(start_time,'%Y%m%d') = DATE_FORMAT(DATE_SUB(#{startTime},INTERVAL 1 DAY),'%Y%m%d')
                </if>
                <if test="type != null and type == '2'.toString">
                    and DATE_FORMAT(start_time,'%Y%m') = DATE_FORMAT(DATE_SUB(#{startTime},INTERVAL 1 MONTH),'%Y%m')
                </if>
                <if test="type != null and type == '3'.toString">
                    and YEAR(start_time) = YEAR(DATE_SUB(#{startTime},INTERVAL 1 QUARTER)) and QUARTER(start_time) = QUARTER(DATE_SUB(#{startTime},INTERVAL 1 QUARTER))
                </if>
                <if test="type != null and type == '4'.toString">
                    and YEAR(start_time) = YEAR(DATE_SUB(#{startTime},INTERVAL 1 YEAR))
                </if>
             group by event_subclass) t3 on t1.eventSubclass = t3.event_subclass
    </select>

</mapper>