ah_jjzhgd_service/securitycontrol-model/securitycontrol-screen/src/main/resources/mapper/SjMaxDeviceMapper.xml

134 lines
5.2 KiB
XML
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

<?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.securitycontrol.screen.mapper.SjMaxDeviceMapper">
<resultMap id="BaseResultMap" type="com.securitycontrol.screen.domain.SjMaxDevice">
<!--@mbg.generated-->
<!--@Table sj_max_device-->
<id column="id" jdbcType="BIGINT" property="id" />
<result column="dev_name" jdbcType="VARCHAR" property="devName" />
<result column="in_time" jdbcType="DATE" property="inTime" />
<result column="out_time" jdbcType="DATE" property="outTime" />
<result column="used_day" jdbcType="VARCHAR" property="usedDay" />
<result column="ein_day" property="einDay"/>
<result column="actual_count" property="actualCount"/>
<result column="date" property="date"/>
<result column="should_count" property="shouldCount"/>
<result column="team_leader" property="teamLeader"/>
<result column="team_name" property="teamName"/>
<result column="total_people" property="totalPeople"/>
<result column="utilization_rate" property="utilizationRate"/>
<result column="work_type" property="workType"/>
</resultMap>
<sql id="Base_Column_List">
<!--@mbg.generated-->
id, dev_name, in_time, out_time, used_day
</sql>
<select id="selectDeviceEcharts" resultMap="BaseResultMap">
SELECT
dev_name,
-- 入场天数:如果未出场,则算到今天
IFNULL(SUM(
DATEDIFF(IF(out_time IS NOT NULL AND out_time &lt; CURDATE(), out_time, CURDATE()), in_time) + 1
), 0) AS ein_day,
-- 使用天数直接求和NULL 显示为 0
IFNULL(SUM(used_day), 0) AS used_day
FROM sj_max_device
WHERE
-- 确保有入场时间
in_time IS NOT NULL
-- 入场时间不能在未来
AND in_time &lt;= CURDATE()
GROUP BY dev_name
ORDER BY ein_day DESC;
</select>
<select id="selectWorkerEcharts" resultMap="BaseResultMap">
SELECT
date_list.dt AS date,
COALESCE(should.should_count, 0) AS should_count,
COALESCE(actual.actual_count, 0) AS actual_count
FROM (
SELECT DATE_ADD(#{startTime}, INTERVAL (ones.a + tens.a * 10) DAY) AS dt
FROM
(SELECT 0 AS a UNION ALL SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3
UNION ALL SELECT 4 UNION ALL SELECT 5 UNION ALL SELECT 6 UNION ALL SELECT 7
UNION ALL SELECT 8 UNION ALL SELECT 9) AS ones
CROSS JOIN
(SELECT 0 AS a UNION ALL SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3
UNION ALL SELECT 4 UNION ALL SELECT 5) AS tens
WHERE DATE_ADD(#{startTime}, INTERVAL (ones.a + tens.a * 10) DAY) &lt;= #{endTime}
) AS date_list
-- 应到人数:每天 = 班组总人数(固定)
CROSS JOIN (
SELECT
COUNT(*) AS should_count
FROM sj_team_people
WHERE team_id IS NOT NULL -- 可按 team_id 过滤
) AS should -- 每天都显示相同人数
-- 实到人数:按天统计 on_time 在当天的人数
LEFT JOIN (
SELECT
DATE(o.on_time) AS duty_date,
COUNT(DISTINCT o.people_id) AS actual_count
FROM sj_on_duty o
WHERE o.on_time IS NOT NULL
AND DATE(o.on_time) BETWEEN #{startTime} AND #{endTime}
GROUP BY DATE(o.on_time)
) AS actual ON date_list.dt = actual.duty_date
ORDER BY date_list.dt
</select>
<select id="selectEfficiency" resultMap="BaseResultMap">
SELECT
wt.work_type,
wt.team_name,
wt.team_leader,
tp_count.total_people,
ROUND(
COALESCE(SUM(actual.actual_count), 0) * 100.0 /
((DATEDIFF(#{endTime} , #{startTime}) + 1) * tp_count.total_people),
2
) AS utilization_rate -- 百分比形式(如 86.70
FROM sj_work_team wt
INNER JOIN (
-- 每个班组的总人数
SELECT
team_id,
COUNT(*) AS total_people
FROM sj_team_people
WHERE team_id IS NOT NULL
GROUP BY team_id
) tp_count ON wt.id = tp_count.team_id
CROSS JOIN (
SELECT DATE_ADD(#{startTime}, INTERVAL (ones.a + tens.a * 10) DAY) AS dt
FROM
(SELECT 0 AS a UNION ALL SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3
UNION ALL SELECT 4 UNION ALL SELECT 5 UNION ALL SELECT 6 UNION ALL SELECT 7
UNION ALL SELECT 8 UNION ALL SELECT 9) AS ones
CROSS JOIN
(SELECT 0 AS a UNION ALL SELECT 1 UNION ALL SELECT 2 UNION ALL SELECT 3
UNION ALL SELECT 4 UNION ALL SELECT 5) AS tens
WHERE DATE_ADD(#{startTime}, INTERVAL (ones.a + tens.a * 10) DAY) &lt;= #{endTime}
) AS date_list
-- 关联每天实到人数
LEFT JOIN (
SELECT
o.team_id,
DATE(o.on_time) AS duty_date,
COUNT(DISTINCT o.people_id) AS actual_count
FROM sj_on_duty o
WHERE o.on_time IS NOT NULL
AND DATE(o.on_time) BETWEEN #{startTime} AND #{endTime}
GROUP BY o.team_id, DATE(o.on_time)
) AS actual
ON wt.id = actual.team_id
AND date_list.dt = actual.duty_date
-- 参数:开始日期、结束日期(共 6 个 ?
WHERE DATE_ADD(#{startTime}, INTERVAL 0 DAY) BETWEEN #{startTime} AND #{endTime} -- 确保日期范围有效(可选)
GROUP BY
wt.id, wt.team_name, wt.team_leader, tp_count.total_people
ORDER BY utilization_rate DESC
</select>
</mapper>