102 lines
5.0 KiB
XML
102 lines
5.0 KiB
XML
<?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.devchange.mapper.MaDevRetireWarningMapper">
|
||
|
||
|
||
<select id="list" resultType="com.bonus.material.devchange.domain.MaDevInfo">
|
||
select * from (
|
||
SELECT
|
||
sd.dept_name AS propertyUnit,
|
||
mdi.ma_id AS maId,
|
||
mdi.device_name AS name,
|
||
mdi.item_type_model AS specificationModel,
|
||
mdi.`code` AS code,
|
||
ms.supplier_name AS manufacturer,
|
||
mdi.production_date AS productionDate,
|
||
DATE_ADD(mdi.production_date, INTERVAL mdi.max_working_hours YEAR) AS expirationTime,
|
||
mdi.max_working_hours AS expirationYears,
|
||
IF(STR_TO_DATE(production_date, '%Y-%m-%d') IS NOT NULL, DATEDIFF(CURDATE(), STR_TO_DATE(production_date,
|
||
'%Y-%m-%d')), 0) AS daysDiff,
|
||
IF(STR_TO_DATE(production_date, '%Y-%m-%d') IS NOT NULL, TIMESTAMPDIFF(YEAR, STR_TO_DATE(production_date,
|
||
'%Y-%m-%d'), CURDATE()), 0) AS yearsDiff,
|
||
|
||
IF(STR_TO_DATE(DATE_ADD(mdi.production_date, INTERVAL mdi.max_working_hours YEAR), '%Y-%m-%d') IS NOT NULL
|
||
AND STR_TO_DATE(DATE_ADD(mdi.production_date, INTERVAL mdi.max_working_hours YEAR), '%Y-%m-%d') >= CURDATE(), DATEDIFF(STR_TO_DATE(DATE_ADD(mdi.production_date, INTERVAL mdi.max_working_hours YEAR), '%Y-%m-%d'),
|
||
CURDATE()), 0) AS remainingDays,
|
||
|
||
IF(STR_TO_DATE(DATE_ADD(mdi.production_date, INTERVAL mdi.max_working_hours YEAR), '%Y-%m-%d') IS NOT NULL
|
||
AND STR_TO_DATE(DATE_ADD(mdi.production_date, INTERVAL mdi.max_working_hours YEAR), '%Y-%m-%d') >= CURDATE(), TIMESTAMPDIFF(YEAR, CURDATE(),
|
||
STR_TO_DATE(DATE_ADD(mdi.production_date, INTERVAL mdi.max_working_hours YEAR), '%Y-%m-%d')), 0) AS remainingYears,
|
||
|
||
CASE
|
||
-- 告警2:已超期(剩余年限≤0)
|
||
WHEN ROUND(TIMESTAMPDIFF(DAY, mdi.production_date, NOW()) / 365.25, 1) >= mdi.max_working_hours
|
||
THEN CONCAT('告警:已超最大使用年限', ROUND(
|
||
ROUND(TIMESTAMPDIFF(DAY, mdi.production_date, NOW()) / 365.25, 1) - mdi.max_working_hours,
|
||
1
|
||
), '年')
|
||
-- 告警1:未超期,但剩余可用年限≤1年(相差小于等于1年)
|
||
WHEN (mdi.max_working_hours - ROUND(TIMESTAMPDIFF(DAY, mdi.production_date, NOW()) / 365.25, 1)) <= 1
|
||
THEN CONCAT('告警:即将超期,剩余可用年限', ROUND(
|
||
mdi.max_working_hours - ROUND(TIMESTAMPDIFF(DAY, mdi.production_date, NOW()) / 365.25, 1),
|
||
1
|
||
), '年')
|
||
-- 正常:未超期,且剩余可用年限>1年(相差大于1年)
|
||
ELSE CONCAT('正常:剩余可用年限', ROUND(
|
||
mdi.max_working_hours - ROUND(TIMESTAMPDIFF(DAY, mdi.production_date, NOW()) / 365.25, 1),
|
||
1
|
||
), '年')
|
||
END AS status
|
||
FROM
|
||
ma_dev_info mdi
|
||
INNER JOIN ma_type_view mtv ON mtv.typeId = mdi.type_id
|
||
LEFT JOIN jj_sing_project jsp ON mdi.on_project = jsp.pro_code
|
||
LEFT JOIN sys_dept sd ON sd.dept_id = mdi.on_company
|
||
LEFT JOIN (SELECT max( next_check_time) next_check_time,ma_id from ma_dev_qc GROUP BY ma_id ) mdq on
|
||
mdi.ma_id=mdq.ma_id
|
||
LEFT JOIN ma_supplier ms ON ms.supplier_id = mdi.supplier_id
|
||
LEFT JOIN sys_cnarea sc ON sc.area_code = mdi.province_id
|
||
WHERE mdi.is_active = 1 and mdi.entry_status = '1' AND mdi.ma_status != '99'
|
||
<if test="name != null and name != ''">
|
||
AND mdi.device_name like concat('%',#{name},'%')
|
||
</if>
|
||
<if test="manufacturerId != null and manufacturerId != ''">
|
||
AND mdi.supplier_id like concat('%',#{manufacturerId},'%')
|
||
</if>
|
||
<if test="companyId != null">
|
||
AND mdi.on_company = #{companyId}
|
||
</if>
|
||
) a
|
||
<where>
|
||
<if test="actualStartYear != null and actualStartYear != ''">
|
||
and yearsDiff between #{actualStartYear} and #{actualStopYear}
|
||
</if>
|
||
<if test="remainingStartYear != null and remainingStartYear != ''">
|
||
and remainingYears between #{remainingStartYear} and #{remainingStopYear}
|
||
</if>
|
||
<if test="isWarn != null and isWarn != ''">
|
||
<if test="isWarn == 1">
|
||
AND status like concat('%','告警','%')
|
||
</if>
|
||
<if test="isWarn == 0">
|
||
AND status like concat('%','正常','%')
|
||
</if>
|
||
</if>
|
||
</where>
|
||
ORDER BY
|
||
-- 1. 先按状态类型排序:告警在前,正常在后
|
||
CASE
|
||
WHEN a.status LIKE '%告警%' THEN 0
|
||
ELSE 1
|
||
END,
|
||
-- 2. 告警内部:已超期在前,即将超期在后
|
||
CASE
|
||
WHEN a.status LIKE '%已超%' THEN 0
|
||
WHEN a.status LIKE '%即将超期%' THEN 1
|
||
ELSE 2
|
||
END,
|
||
-- 3. 按剩余可用年限从少到多排序(数值排序)
|
||
(a.expirationYears - ROUND(TIMESTAMPDIFF(DAY, a.productionDate, NOW()) / 365.25, 1))
|
||
</select>
|
||
</mapper>
|