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

460 lines
20 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.scrap.mapper.ScrapMapper">
<select id="getInStockList" resultType="com.bonus.material.scrap.domain.ToBeScrap">
SELECT t.* FROM (
SELECT
CONCAT(tl.id,'-','工具') as keyId,
tl.id,
'工具' AS type,
'2' as devType,
tl.type_id as typeId,
CONCAT(tt2.type_name, '/', tt3.type_name, '/', tt4.type_name) AS groupName,
tt4.type_name as typeName,
tt5.type_name as typeModelName,
CASE tl.manage_mode WHEN 0 THEN '编码管理' ELSE '数量管理' END manageMode,
tl.tool_code as `devCode`,
CASE tl.manage_mode WHEN 0 THEN IFNULL(tl.total_num, 0) ELSE IFNULL(tl.available_num, 0) END inStockNum,
'-' AS productionDate,
'-' AS expirationYears,
'-' AS status
FROM
tool_ledger tl
LEFT JOIN tool_type tt5 on tt5.type_id = tl.type_id
LEFT JOIN tool_type tt4 on tt4.type_id = tt5.parent_id
LEFT JOIN tool_type tt3 on tt3.type_id = tt4.parent_id
LEFT JOIN tool_type tt2 on tt2.type_id = tt3.parent_id
WHERE ((tl.manage_mode = '1' AND tl.available_num IS NOT NULL AND tl.available_num > 0)
OR (tl.manage_mode = '0' AND tl.`status` = '0'))
<if test="typeName != null and typeName!=''">
AND tt4.type_name like concat('%',#{typeName},'%')
</if>
<if test="typeModelName != null and typeModelName!=''">
AND tt5.type_name like concat('%',#{typeModelName},'%')
</if>
<if test="devCode != null and devCode!=''">
AND tl.tool_code like concat('%',#{devCode},'%')
</if>
<if test="manageType != null and manageType!=''">
AND tl.manage_mode = #{manageType}
</if>
<if test="companyId!=null">
AND tl.company_id = #{companyId}
</if>
<if test='devType == "1"'>
AND 1=0
</if>
UNION
SELECT * FROM (
SELECT
CONCAT(mdi.ma_id,'-','装备') as keyId,
mdi.ma_id as id,
'装备' as type,
'1' as devType,
mdi.type_id as typeId,
CONCAT(mt2.type_name, '/', mt3.type_name, '/', mt4.type_name) AS groupName,
mdi.device_name as typeName,
mdi.item_type_model as typeModelName,
'编码管理' as manageMode,
mdi.`code` as `devCode`,
mdi.device_count as inStockNum,
mdi.production_date AS productionDate,
mdi.max_working_hours AS expirationYears,
CASE
-- 告警2已超期剩余年限≤0
WHEN ROUND(TIMESTAMPDIFF(DAY, mdi.production_date, NOW()) / 365.25, 1) &gt;= 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)) &lt;= 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
LEFT JOIN ma_type mt5 on mt5.type_id = mdi.type_id
LEFT JOIN ma_type mt4 on mt4.type_id = mt5.parent_id
LEFT JOIN ma_type mt3 on mt3.type_id = mt4.parent_id
LEFT JOIN ma_type mt2 on mt2.type_id = mt3.parent_id
WHERE mdi.ma_status = '1'
<if test="typeName != null and typeName!=''">
AND mdi.device_name like concat('%',#{typeName},'%')
</if>
<if test="typeModelName != null and typeModelName!=''">
AND mdi.item_type_model like concat('%',#{typeModelName},'%')
</if>
<if test="devCode != null and devCode!=''">
AND mdi.`code` like concat('%',#{devCode},'%')
</if>
<if test="companyId != null">
AND mdi.on_company = #{companyId}
</if>
<if test='devType == "2"'>
AND 1=0
</if>
) a
) t
ORDER BY
-- 1. 先按状态类型排序:告警在前,正常在后
CASE
WHEN t.status LIKE '%告警%' THEN 0
ELSE 1
END,
-- 2. 告警内部:已超期在前,即将超期在后
CASE
WHEN t.status LIKE '%已超%' THEN 0
WHEN t.status LIKE '%即将超期%' THEN 1
ELSE 2
END,
-- 3. 按剩余可用年限从少到多排序(数值排序)
(t.expirationYears - ROUND(TIMESTAMPDIFF(DAY, t.productionDate, NOW()) / 365.25, 1))
</select>
<select id="getScrapApplyList" resultType="com.bonus.material.scrap.domain.ToBeScrap">
SELECT
cdc.id,
cdc.code,
SUM(CASE cdcd.dev_type WHEN 1 THEN cdcd.num ELSE 0 END) as equipmentNum,
SUM(CASE cdcd.dev_type WHEN 2 THEN cdcd.num ELSE 0 END) as toolNum,
cdc.review_status as reviewStatus,
cdc.create_user as createUser,
cdc.create_time as createTime,
cdc.company_id as companyId
FROM
cs_device_change cdc
LEFT JOIN cs_device_change_details cdcd ON cdcd.change_id = cdc.id
WHERE cdc.type = '3'
and cdc.del_flag='0'
<if test="reviewStatus != null and reviewStatus!=''">
AND cdc.review_status = #{reviewStatus}
</if>
<if test="startTime!=null and startTime!='' and endTime!=null and endTime!='' ">
AND cdc.create_time BETWEEN CONCAT(#{startTime}, ' 00:00:00') AND CONCAT(#{endTime}, ' 23:59:59')
</if>
<if test="companyId != null and changeId != 1">
and cdc.company_id
in (
select dept_id from sys_dept where dept_id= #{companyId}
union
select dept_id from sys_dept where parent_id= #{companyId}
union
select dept_id from sys_dept where parent_id in (select dept_id from sys_dept where parent_id= #{companyId})
)
</if>
GROUP BY cdc.id
ORDER BY
-- 实现自定义状态排序:审核中(2) > 已驳回(1) > 已通过(0)
CASE cdc.review_status
WHEN 2 THEN 2
WHEN 1 THEN 1
WHEN 0 THEN 0
ELSE 3
END ASC,
-- 按申请时间降序排序(后申请的在前)
cdc.create_time DESC
</select>
<select id="getScrapDetailsList" resultType="com.bonus.material.scrap.domain.ToBeScrap">
SELECT DISTINCT cdcd.id,cdcd.dev_type_id as typeId, 2 as devType,
tl.id as devId,
'工具' as type,
CONCAT(tt2.type_name, '/', tt3.type_name, '/', tt4.type_name) AS groupName,
tt4.type_name as typeName,
tt5.type_name as typeModelName,
CASE
WHEN cdcd.dev_code is null THEN
'数量管理'
ELSE
'编码管理'
END manageMode,
cdcd.dev_code as `devCode`,
cdcd.num as scrapNum,
cdcd.is_scrap as isScrap,
cdcd.review_status as reviewStatus,
CASE cdcd.review_status
WHEN 0 THEN
'待审核'
WHEN 1 THEN
'通过'
WHEN 2 THEN
'驳回'
END status,
cdcd.repair_time as repairTime,
cdcd.reason_val as reasonVal,
CASE is_scrap
WHEN 0 THEN
repair_url
ELSE
reason_url
END scrapUrl,
tl.available_num as inStockNum
FROM cs_device_change_details cdcd
LEFT JOIN tool_ledger tl
ON cdcd.dev_type = '2'
AND cdcd.dev_type_id = tl.type_id
AND (cdcd.dev_code is null OR cdcd.dev_code = tl.tool_code)
LEFT JOIN tool_type tt5 on tt5.type_id = cdcd.dev_type_id
LEFT JOIN tool_type tt4 on tt4.type_id = tt5.parent_id
LEFT JOIN tool_type tt3 on tt3.type_id = tt4.parent_id
LEFT JOIN tool_type tt2 on tt2.type_id = tt3.parent_id
WHERE cdcd.change_id = #{id}
and cdcd.dev_type = '2'
and cdcd.del_flag = '0'
GROUP BY cdcd.id
UNION
SELECT DISTINCT cdcd.id,cdcd.dev_type_id as typeId, 1 as devType,
mdi.ma_id as devId,
'装备' as type,
CONCAT(mt2.type_name, '/', mt3.type_name, '/', mt4.type_name) AS groupName,
mdi.device_name as typeName,
mdi.item_type_model as typeModelName,
CASE
WHEN cdcd.dev_code is null THEN
'数量管理'
ELSE
'编码管理'
END manageMode,
cdcd.dev_code as `devCode`,
cdcd.num as scrapNum,
cdcd.is_scrap as isScrap,
cdcd.review_status as reviewStatus,
CASE cdcd.review_status
WHEN 0 THEN
'待审核'
WHEN 1 THEN
'通过'
WHEN 2 THEN
'驳回'
END status,
cdcd.repair_time as repairTime,
cdcd.reason_val as reasonVal,
CASE is_scrap
WHEN 0 THEN
repair_url
ELSE
reason_url
END url,
'1' as inStockNum
FROM cs_device_change_details cdcd
LEFT JOIN ma_dev_info mdi on mdi.code = cdcd.dev_code
LEFT JOIN ma_type mt5 on mt5.type_id = mdi.type_id
LEFT JOIN ma_type mt4 on mt4.type_id = mt5.parent_id
LEFT JOIN ma_type mt3 on mt3.type_id = mt4.parent_id
LEFT JOIN ma_type mt2 on mt2.type_id = mt3.parent_id
WHERE cdcd.change_id = #{id}
and cdcd.dev_type = '1'
and cdcd.del_flag = '0'
GROUP BY cdcd.id
</select>
<insert id="addDeviceChangeApply" keyProperty="id" useGeneratedKeys="true">
insert into cs_device_change(type, code, review_status, create_user, create_time, del_flag, company_id)
values (3, #{code}, #{reviewStatus}, #{createUser}, NOW(), '0', #{companyId})
</insert>
<insert id="addScrapChangeApplyDetails">
insert into cs_device_change_details(
change_id,
<if test="devCode != null and devCode!=''">dev_code,</if>
<if test="typeId != null and typeId!=''">dev_type_id,</if>
<if test="devType != null and devType!=''">dev_type,</if>
<if test="scrapNum != null">num,</if>
<if test="scrapNum != null">real_num,</if>
<if test="reasonVal != null and reasonVal!=''">reason_val,</if>
<if test="scrapUrl != null and scrapUrl!=''">reason_url,</if>
is_scrap,
<if test="createUser != null">create_user,</if>
review_status,
create_time
)
values (
#{changeId},
<if test="devCode != null and devCode!=''">#{devCode},</if>
<if test="typeId != null and typeId!=''">#{typeId},</if>
<if test="devType != null and devType!=''">#{devType},</if>
<if test="scrapNum != null">#{scrapNum},</if>
<if test="scrapNum != null">#{scrapNum},</if>
<if test="reasonVal != null and reasonVal!=''">#{reasonVal},</if>
<if test="scrapUrl != null and scrapUrl!=''">#{scrapUrl},</if>
1,
<if test="createUser != null">#{createUser},</if>
'0',
NOW()
)
</insert>
<select id="getMonthMaxOrderByDate" resultType="int">
select COUNT(*)
from cs_device_change
where
month (create_time) = #{month}
and year (create_time) = #{year}
and `type` = #{type}
</select>
<update id="auditData">
update cs_device_change_details
set review_status = #{reviewStatus},
review_by = #{createUser},
review_time = now()
where id = #{id}
</update>
<select id="selectByTypeIdAndCode" resultType="com.bonus.material.scrap.domain.ToBeScrap">
SELECT
tl.id,
CASE tl.manage_mode WHEN 0 THEN '编码管理' WHEN 1 THEN '数量管理' END manageMode
FROM
tool_ledger tl
WHERE
tl.type_id = #{typeId}
<if test="devCode != null and devCode!=''">
and tl.tool_code = #{devCode}
</if>
limit 1
</select>
<insert id="addToolLifecycleByRepair">
insert into tool_lifecycle(
ledger_id,
<if test="devCode != null and devCode != ''">tool_code,</if>
action_type,
<if test="scrapNum != null">change_num,</if>
status_before,
status_after,
<if test="createBy != null">operator_id,</if>
<if test="createUser != null">operator_name,</if>
operate_time,
create_time
)
values (
#{id},
<if test="devCode != null and devCode!=''">#{devCode},</if>
'退役',
<if test="scrapNum != null">#{scrapNum},</if>
'在库',
'退役',
<if test="createBy != null">#{createBy},</if>
<if test="createUser != null">#{createUser},</if>
NOW(),
NOW()
)
</insert>
<update id="updateToolLifecycle">
update
tool_ledger
set
available_num = available_num - #{scrapNum},
scrap_num = scrap_num + #{scrapNum},
status = '3',
update_time = now()
where
id = #{id}
</update>
<update id="updateMaDevInfo">
update
ma_dev_info
set
ma_status = '99',
change_status='4',
<if test="createBy != null">
update_by = #{createBy},
</if>
update_time = now()
where
type_id = #{typeId} and code = #{devCode}
</update>
<select id="selectCountByChangeId" resultType="int">
select count(1) from cs_device_change_details where change_id = #{changeId} and review_status = 0
</select>
<select id="getDetail" resultType="com.bonus.material.scrap.domain.ToBeScrap">
SELECT CONCAT(mdi.ma_id, '-', '装备') as keyId,
mdi.ma_id as id,
'装备' as type,
'1' as devType,
mdi.type_id as typeId,
CONCAT(mt2.type_name, '/', mt3.type_name, '/', mt4.type_name) AS groupName,
mdi.device_name as typeName,
mdi.item_type_model as typeModelName,
'编码管理' as manageMode,
mdi.`code` as `devCode`,
mdi.device_count as inStockNum,
mdi.production_date AS productionDate,
mdi.max_working_hours AS expirationYears,
CASE
-- 告警2已超期剩余年限≤0
WHEN ROUND(TIMESTAMPDIFF(DAY, mdi.production_date, NOW()) / 365.25, 1) &gt;= 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)) &lt;=
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
LEFT JOIN ma_type mt5 on mt5.type_id = mdi.type_id
LEFT JOIN ma_type mt4 on mt4.type_id = mt5.parent_id
LEFT JOIN ma_type mt3 on mt3.type_id = mt4.parent_id
LEFT JOIN ma_type mt2 on mt2.type_id = mt3.parent_id
WHERE mdi.ma_id = #{id}
</select>
<select id="getDetailsNum" resultType="java.math.BigDecimal">
SELECT IFNULL(SUM(cdcd.num),0)
FROM cs_device_change_details cdcd
LEFT JOIN cs_device_change cdc ON cdc.id = cdcd.change_id
WHERE cdcd.dev_type_id = #{typeId}
AND cdc.review_status in ('1','0','5') AND cdc.type ='3'
and cdcd.del_flag ='0'
<if test="devCode!=null and devCode!=&quot;/&quot;">
AND cdcd.dev_code = #{devCode}
</if>
<if test="id!=null and id!=''">
and cdcd.id not in( #{id})
</if>
GROUP BY
cdcd.dev_type_id
</select>
<update id="updateChangeStatus">
update cs_device_change set review_status = #{reviewStatus} where id = #{changeId}
</update>
<delete id="deleteChangeInfo">
update cs_device_change set del_flag = '1' where id = #{id}
</delete>
</mapper>