Bonus-Cloud-Material-Mall/bonus-modules/bonus-material-mall/src/main/resources/mapper/material/device/MaDevQcMapper.xml

232 lines
9.4 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.bonus.material.device.mapper.MaDevQcMapper">
<update id="updateById">
update ma_dev_qc
<set>
<if test="qcUser != null and qcUser != ''">qc_user = #{qcUser},</if>
<if test="qcTime != null ">qc_time = #{qcTime},</if>
<if test="nextCheckTime != null ">next_check_time = #{nextCheckTime},</if>
</set>
where id = #{id}
</update>
<update id="updateFileId">
update ma_dev_qc set file_id = #{fileId} where id = #{id}
</update>
<delete id="deleteDevQcByFileId">
delete from ma_dev_qc where file_id = #{fileId}
</delete>
<insert id="insertDevQc" useGeneratedKeys="true" keyProperty="id">
insert into ma_dev_qc
<trim prefix="(" suffix=")" suffixOverrides=",">
<if test="maId != null">ma_id,</if>
<if test="nextCheckTime != null">next_check_time,</if>
<if test="qcCode != null and qcCode != ''">qc_code,</if>
<if test="qcUser != null and qcUser != ''">qc_user,</if>
<if test="qcCom != null and qcCom != ''">qc_com,</if>
<if test="qcTime != null">qc_time,</if>
<if test="createBy != null">create_by,</if>
<if test="createTime != null">create_time,</if>
<if test="phonenumber != null">phonenumber,</if>
</trim>
<trim prefix="values (" suffix=")" suffixOverrides=",">
<if test="maId != null">#{maId},</if>
<if test="nextCheckTime != null">#{nextCheckTime},</if>
<if test="qcCode != null and qcCode != ''">#{qcCode},</if>
<if test="qcUser != null and qcUser != ''">#{qcUser},</if>
<if test="qcCom != null and qcCom != ''">#{qcCom},</if>
<if test="qcTime != null">#{qcTime},</if>
<if test="createBy != null">#{createBy},</if>
<if test="createTime != null">#{createTime},</if>
<if test="phonenumber != null">#{phonenumber},</if>
</trim>
</insert>
<select id="selectTaskNumByMonth" resultType="java.lang.String">
SELECT SUBSTRING(qc_code, - 4) as code
FROM ma_dev_qc
WHERE DATE_FORMAT(create_time, '%y%m') = DATE_FORMAT(#{date}, '%y%m')
ORDER BY create_time DESC LIMIT 1
</select>
<select id="selectDevQcList" resultType="com.bonus.material.device.domain.MaDevQc">
SELECT
m1.id,
m2.ma_id AS maId,
m2.CODE AS deviceCode,
m2.device_name AS deviceName,
m2.item_type_model AS itemTypeModel,
m1.qc_code AS qcCode,
m1.qc_user AS qcUser,
m1.qc_time AS qcTime,
m1.next_check_time AS nextCheckTime,
mdq1.qc_time AS upCheckTime,
m1.create_time AS updateTime,
aa.create_time AS createTime,
m1.phonenumber AS phonenumber,
CASE
WHEN mdq.next_check_time &lt;= CURRENT_DATE() THEN '已超期'
WHEN mdq.next_check_time &lt;= DATE_ADD(CURRENT_DATE(), INTERVAL 1 MONTH) THEN '一月内到期'
ELSE '正常'
END AS alert
FROM
ma_dev_info m2
LEFT JOIN ma_dev_qc m1 ON m1.ma_id = m2.ma_id
LEFT JOIN ( SELECT count(*) as num, ma_id, MAX( qc_time ) AS max_qc_time FROM ma_dev_qc GROUP BY ma_id )
latest_qc ON m1.ma_id = latest_qc.ma_id
LEFT JOIN ( SELECT ma_id, min( create_time ) AS create_time FROM ma_dev_qc GROUP BY ma_id ) aa ON m1.ma_id =
aa.ma_id
LEFT JOIN (SELECT max( next_check_time) next_check_time,ma_id from ma_dev_qc GROUP BY ma_id ) mdq on
m2.ma_id=mdq.ma_id
LEFT JOIN (
SELECT
ma_id,
qc_time
FROM (
-- 内层按ma_id分组给next_check_time降序排名
SELECT
ma_id,
qc_time,
ROW_NUMBER() OVER (PARTITION BY ma_id ORDER BY qc_time DESC) AS rn
FROM ma_dev_qc
-- 过滤掉next_check_time为NULL的记录可选根据业务需求
WHERE qc_time IS NOT NULL
) t
-- 筛选排名为2的记录第二大
WHERE t.rn = 2
) mdq1 ON m2.ma_id = mdq1.ma_id
<where>
m2.is_active = '1' and m2.entry_status = '1' AND m2.ma_status != '99'
<if test="deviceCode != null and deviceCode != ''">
and m2.code like concat('%',#{deviceCode},'%')
</if>
<if test="qcUser != null and qcUser != ''">
and m1.qc_user like concat('%',#{qcUser},'%')
</if>
<if test="minNum != null and maxNum != null">
and latest_qc.num BETWEEN #{minNum} AND #{maxNum}
</if>
<if test="qcCode != null and qcCode != ''">
and m1.qc_code like concat('%',#{qcCode},'%')
</if>
<if test="qcStartTime != null and qcStartTime != '' and qcEndTime != null and qcEndTime != ''">
and DATE_FORMAT(m1.next_check_time,'%Y-%m-%d') between #{qcStartTime} and #{qcEndTime}
</if>
<if test="createStartTime != null and createStartTime != '' and createEndTime != null and createEndTime != ''">
and DATE_FORMAT(m1.create_time,'%Y-%m-%d') between #{createStartTime} and #{createEndTime}
</if>
<if test="qcCom != null and qcCom != ''">
and m2.on_company = #{qcCom}
</if>
<if test="alert != null and alert != ''">
<choose>
<!-- 筛选“已超期” -->
<when test="alert == '已超期'">
and mdq.next_check_time &lt;= CURRENT_DATE()
</when>
<!-- 筛选“一月内到期” -->
<when test="alert == '一月内到期'">
and mdq.next_check_time &lt;= DATE_ADD(CURRENT_DATE(), INTERVAL 1 MONTH)
</when>
<!-- 筛选“正常” -->
<when test="alert == '正常'">
and mdq.next_check_time &gt; DATE_ADD(CURRENT_DATE(), INTERVAL 1 MONTH)
</when>
</choose>
</if>
</where>
GROUP BY m2.ma_id
ORDER BY
-- 自定义排序:已超期 > 一月内到期 > 正常(可根据需求调整顺序)
CASE alert
WHEN '已超期' THEN 1
WHEN '一月内到期' THEN 2
WHEN '正常' THEN 3
END ASC,
m2.ma_id ASC
</select>
<select id="selectQcList" resultType="com.bonus.material.device.domain.MaDevQc">
SELECT
mdq.*,
su.nick_name AS nickName,
bfi.url AS url
FROM
ma_dev_qc mdq
LEFT JOIN bm_file_info bfi ON bfi.model_id = mdq.ma_id and bfi.task_id = mdq.id
LEFT JOIN sys_user su ON mdq.create_by = su.user_id
WHERE
bfi.task_type = 17
AND bfi.file_type = 4
AND bfi.model_id = #{maId}
<if test="qcCode != null and qcCode != ''">
and mdq.qc_code like concat('%',#{qcCode},'%')
</if>
<if test="qcStartTime != null and qcStartTime != '' and qcEndTime != null and qcEndTime != ''">
and DATE_FORMAT(mdq.qc_time,'%Y-%m-%d') between #{qcStartTime} and #{qcEndTime}
</if>
<if test="createStartTime != null and createStartTime != '' and createEndTime != null and createEndTime != ''">
and DATE_FORMAT(mdq.create_time,'%Y-%m-%d') between #{createStartTime} and #{createEndTime}
</if>
ORDER BY mdq.qc_time DESC
</select>
<select id="getQcList" resultType="com.bonus.material.device.domain.MaDevQc">
SELECT
mdc.qc_time,
mdc.id,
mdc.ma_id,
mt.maintenance_alarm_day,
sd.dept_name comName
FROM
ma_dev_qc mdc
LEFT JOIN ma_dev_info mdi ON mdc.ma_id = mdi.ma_id
LEFT JOIN ma_type mt ON mdi.type_id = mt.type_id
LEFT JOIN sys_dept sd ON mdc.qc_com = sd.dept_id
WHERE
mdc.ma_id = #{maId}
LIMIT 10
</select>
<select id="getQcListByOne" resultType="com.bonus.material.device.domain.MaDevQc">
SELECT
mdc.id,
mdc.qc_time,
mdc.ma_id,
mt.maintenance_alarm_day,
mdc.qc_user,
mdc.next_check_time,
sd.dept_name comName
FROM
ma_dev_qc mdc
LEFT JOIN ma_dev_info mdi ON mdc.ma_id = mdi.ma_id
LEFT JOIN ma_type mt ON mdi.type_id = mt.type_id
LEFT JOIN sys_dept sd ON mdc.qc_com = sd.dept_id
WHERE
mdc.ma_id = #{maId}
order by mdc.qc_time desc
LIMIT 1
</select>
<select id="checkQcTime" resultType="com.bonus.material.device.domain.MaDevQc">
SELECT
mdc.create_time,
mdc.qc_com,
mdc.ma_id,
mdi.device_name,
mdi.creator as own_id,
sd.dept_name as comName,
mdc.next_check_time
FROM
ma_dev_qc mdc
left join ma_dev_info mdi on mdi.ma_id = mdc.ma_id
left join sys_dept sd on mdc.qc_com = sd.dept_id
where mdc.next_check_time &lt; now()
</select>
<select id="selectDevQcListByMaId" resultType="java.lang.Integer">
select count(*) from ma_dev_qc where ma_id = #{maId}
</select>
</mapper>