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

448 lines
18 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.back.mapper.BackChangeMapper">
<insert id="addChangeInfoNew" keyProperty="id" useGeneratedKeys="true">
insert into cs_device_change(change_status, type, lease_type, pro_code, pro_name,
pro_type, voltage_level, use_unit, pro_province, pro_city,
pro_county, create_time, create_user, del_flag, change_unit, code, use_time,use_start_time,use_end_time,review_status)
values ( #{changeStatus}, #{type}, #{leaseType}, #{proCode}, #{proName}, #{proType},
#{voltageLevel}, #{useUnit}, #{proProvince}, #{proCity}, #{proCounty},
now(), #{createBy}, 0, #{changeUnit}, #{code}, #{useTime}, #{useStartTime},#{useEndTime},#{taskStatus})
</insert>
<insert id="addDetails">
insert into cs_device_change_details(change_id, dev_code, dev_type_id, dev_type, num, use_time,use_start_time,use_end_time,
create_user, create_time, update_user, update_time, del_flag, is_repair, real_num)
values
<foreach collection="list" item="item" separator=",">
(#{item.changeId},#{item.devCode},#{item.typeId},#{item.devType},#{item.num},#{item.useTime},#{item.useStartTime},#{item.useEndTime},
#{item.createBy}, #{item.createTime},#{item.updateBy}, #{item.updateTime}, 0, #{item.isRepair}, #{item.realNum})
</foreach>
</insert>
<update id="updateCsDevInfo">
update cs_device_change
<set>
<if test="proCode != null and proCode != ''">
pro_code = #{proCode},
</if>
<if test="proName != null and proName != ''">
pro_name = #{proName},
</if>
<if test="proType != null and proType != ''">
pro_type = #{proType},
</if>
<if test="voltageLevel != null and voltageLevel != ''">
voltage_level = #{voltageLevel},
</if>
<if test="useUnit != null and useUnit != ''">
use_unit = #{useUnit},
</if>
<if test="proProvince != null and proProvince != ''">
pro_province = #{proProvince},
</if>
<if test="proCity != null and proCity != ''">
pro_city = #{proCity},
</if>
<if test="proCounty != null and proCounty != ''">
pro_county = #{proCounty},
</if>
<if test="useTime != null">
use_time = #{useTime},
</if>
<if test="useStartTime != null">
use_start_time = #{useStartTime},
</if>
<if test="useEndTime != null">
use_end_time = #{useEndTime},
</if>
<if test="updateBy != null and updateBy != ''">
update_user = #{updateBy},
</if>
<if test="taskStatus != null and taskStatus != ''">
review_status = #{taskStatus},
</if>
update_time = NOW()
</set>
where id = #{id}
</update>
<update id="approve">
update cs_device_change
<set>
<if test="taskStatus != null and taskStatus != ''">
review_status = #{taskStatus},
</if>
<if test="updateBy != null and updateBy != ''">
review_by = #{updateBy},
</if>
review_time = NOW()
</set>
where id = #{id}
</update>
<update id="updateMaDevInfo">
UPDATE ma_dev_info
set ma_status = #{maStatus}
WHERE code = #{devCode}
</update>
<update id="updateToolInfo">
UPDATE tool_ledger
set status = #{maStatus},
in_num = IFNULL(in_num, 0) - 1,
available_num = IFNULL(available_num, 0) + 1
WHERE tool_code = #{devCode}
</update>
<update id="updateToolInfoNum">
UPDATE tool_ledger
set
in_num = IFNULL(in_num, 0) - #{num},
available_num = IFNULL(available_num, 0) + #{num}
WHERE type_id = #{typeId}
</update>
<update id="updateToolInfoRepair">
UPDATE tool_ledger
set status = #{maStatus},
in_num = IFNULL(in_num, 0) - 1,
repair_num = IFNULL(repair_num, 0) + 1
WHERE tool_code = #{devCode}
</update>
<update id="updateToolInfoRepairNum">
UPDATE tool_ledger
set
in_num = IFNULL(in_num, 0) - #{num},
available_num = IFNULL(available_num, 0) + #{num} - #{realNum},
repair_num = IFNULL(repair_num, 0) + #{realNum}
WHERE type_id = #{typeId}
</update>
<delete id="deleteChangeDetails">
update cs_device_change_details set del_flag = '1' where change_id = #{id}
</delete>
<delete id="deleteChangeInfo">
update cs_device_change set del_flag = '1' where id = #{id}
</delete>
<select id="getDevDetailsInfo" resultType="com.bonus.material.back.domain.BackCsDeviceDetails">
SELECT
CASE
WHEN mt.level = 1 THEN mt.type_name
WHEN mt.level = 2 THEN CONCAT(mt1.type_name, '>', mt.type_name)
WHEN mt.level = 3 THEN CONCAT(mt2.type_name, '>', mt1.type_name, '>', mt.type_name)
WHEN mt.level = 4 THEN CONCAT(mt3.type_name, '>', mt2.type_name, '>', mt1.type_name, '>',
mt.type_name)
WHEN mt.level = 5 THEN CONCAT(mt4.type_name, '>', mt3.type_name, '>', mt2.type_name, '>',
mt1.type_name,'>', mt.type_name)
WHEN mt.level = 6 THEN CONCAT(mt5.type_name, '>', mt4.type_name, '>', mt3.type_name, '>',
mt2.type_name,'>', mt1.type_name, '>', mt.type_name)
ELSE mt.type_name
END AS category,
mdi.device_name AS typeName,
mdi.item_type_model AS typeModelName,
mdi.manage_type AS manageType,
mdi.code AS devCode,
mdi.device_count AS useNum,
1 AS devType,
mdi.type_id AS typeId,
mdi.ma_id AS id
FROM ma_dev_info mdi
LEFT JOIN cs_device_change_details cdc ON mdi.code = cdc.dev_code
LEFT JOIN cs_device_change cd ON cd.id = cdc.change_id
LEFT JOIN ma_type mt ON mdi.type_id = mt.type_id
LEFT JOIN ma_type mt1 ON mt.parent_id = mt1.type_id
LEFT JOIN ma_type mt2 ON mt1.parent_id = mt2.type_id
LEFT JOIN ma_type mt3 ON mt2.parent_id = mt3.type_id
LEFT JOIN ma_type mt4 ON mt3.parent_id = mt4.type_id
LEFT JOIN ma_type mt5 ON mt4.parent_id = mt5.type_id
<where>
mdi.is_active = '1' and mdi.ma_status = 2 AND cdc.del_flag = '0'
<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="proCode!=null and proCode!=''">
AND cd.pro_code = #{proCode}
</if>
<if test="devType!=null and devType!=''">
AND cdc.dev_type = #{devType}
</if>
</where>
GROUP BY mdi.code
UNION ALL
SELECT CONCAT(tt4.type_name, '>', tt3.type_name, '>', tt2.type_name) as category,
tt1.type_name as typeName,
tt.type_name as typeModelName,
tl.manage_mode as manageType,
IFNULL(tl.tool_code,'/') as devCode,
IFNULL(tl.in_num, 0) as useNum,
2 as devType,
tl.type_id as typeId,
tl.id as id
FROM tool_ledger tl
LEFT JOIN cs_device_change_details cdc ON tl.tool_code = cdc.dev_code
LEFT JOIN cs_device_change cd ON cd.id = cdc.change_id
LEFT JOIN tool_type tt ON tl.type_id = tt.type_id
LEFT JOIN tool_type tt1 ON tt.parent_id = tt1.type_id
LEFT JOIN tool_type tt2 ON tt1.parent_id = tt2.type_id
LEFT JOIN tool_type tt3 ON tt2.parent_id = tt3.type_id
LEFT JOIN tool_type tt4 ON tt3.parent_id = tt4.type_id
<where>
cdc.del_flag = '0'
<if test="devType!=null and devType!=''">
AND cdc.dev_type = #{devType}
</if>
<if test="manageType!=null and manageType!=''">
AND tl.manage_mode = #{manageType}
</if>
<if test="typeName!=null and typeName!=''">
AND tt1.type_name like concat('%',#{typeName},'%')
</if>
<if test="typeModelName!=null and typeModelName!=''">
AND tt.type_name like concat('%',#{typeModelName},'%')
</if>
<if test="devCode!=null and devCode!=''">
AND tl.tool_code like concat('%',#{devCode},'%')
</if>
<if test="companyId!=null">
AND tl.company_id = #{companyId}
</if>
<if test="proCode!=null and proCode!=''">
AND cd.pro_code = #{proCode}
</if>
</where>
GROUP BY tl.tool_code
HAVING useNum &gt; 0
UNION ALL
SELECT CONCAT(tt4.type_name, '>', tt3.type_name, '>', tt2.type_name) as category,
tt1.type_name as typeName,
tt.type_name as typeModelName,
tl.manage_mode as manageType,
IFNULL(tl.tool_code,'/') as devCode,
IFNULL(tl.in_num, 0) as useNum,
2 as devType,
tl.type_id as typeId,
tl.id as id
FROM tool_ledger tl
LEFT JOIN cs_device_change_details cdc ON tl.type_id = cdc.dev_type_id
LEFT JOIN cs_device_change cd ON cd.id = cdc.change_id
LEFT JOIN tool_type tt ON tl.type_id = tt.type_id
LEFT JOIN tool_type tt1 ON tt.parent_id = tt1.type_id
LEFT JOIN tool_type tt2 ON tt1.parent_id = tt2.type_id
LEFT JOIN tool_type tt3 ON tt2.parent_id = tt3.type_id
LEFT JOIN tool_type tt4 ON tt3.parent_id = tt4.type_id
<where>
cdc.del_flag = '0'
<if test="devType!=null and devType!=''">
AND cdc.dev_type = #{devType}
</if>
<if test="manageType!=null and manageType!=''">
AND tl.manage_mode = #{manageType}
</if>
<if test="typeName!=null and typeName!=''">
AND tt1.type_name like concat('%',#{typeName},'%')
</if>
<if test="typeModelName!=null and typeModelName!=''">
AND tt.type_name like concat('%',#{typeModelName},'%')
</if>
<if test="devCode!=null and devCode!=''">
AND tl.tool_code like concat('%',#{devCode},'%')
</if>
<if test="companyId!=null">
AND tl.company_id = #{companyId}
</if>
<if test="proCode!=null and proCode!=''">
AND cd.pro_code = #{proCode}
</if>
</where>
GROUP BY tl.id
HAVING useNum &gt; 0
</select>
<select id="getMonthMaxOrderByDate" resultType="java.lang.Integer">
select COUNT(*) from cs_device_change
where
month(create_time) = #{month} and year(create_time) = #{year}
<if test="taskType != null and taskType !=''">
and type = #{taskType}
</if>
</select>
<select id="getDevInfoById" resultType="com.bonus.material.back.domain.BackCsDeviceInfo">
select
id as id,
type as type,
lease_type as leaseType,
pro_code as proCode,
pro_name as proName,
pro_type as proType,
voltage_level as voltageLevel,
use_unit as useUnit,
pro_province as proProvince,
pro_city as proCity,
pro_county as proCounty,
use_time as useTime,
use_start_time as useStartTime,
use_end_time as useEndTime,
code as code
from cs_device_change
where id = #{id}
</select>
<select id="getDevDetailsById" resultType="com.bonus.material.back.domain.BackCsDeviceDetails">
SELECT id AS detailsId,
dev_code AS devCode,
dev_type AS devType,
dev_type_id AS typeId,
num AS num,
use_time AS useTime,
use_start_time as useStartTime,
use_end_time as useEndTime,
IFNULL(real_num, 0) AS realNum,
is_repair AS isRepair
FROM cs_device_change_details
where change_id = #{id}
and del_flag = '0'
</select>
<select id="getTypeMaDevInfo" resultType="com.bonus.material.back.domain.BackCsDeviceDetails">
SELECT
CASE
WHEN mt.level = 1 THEN mt.type_name
WHEN mt.level = 2 THEN CONCAT(mt1.type_name, '>', mt.type_name)
WHEN mt.level = 3 THEN CONCAT(mt2.type_name, '>', mt1.type_name, '>', mt.type_name)
WHEN mt.level = 4 THEN CONCAT(mt3.type_name, '>', mt2.type_name, '>', mt1.type_name, '>',
mt.type_name)
WHEN mt.level = 5 THEN CONCAT(mt4.type_name, '>', mt3.type_name, '>', mt2.type_name, '>',
mt1.type_name,'>', mt.type_name)
WHEN mt.level = 6 THEN CONCAT(mt5.type_name, '>', mt4.type_name, '>', mt3.type_name, '>',
mt2.type_name,'>', mt1.type_name, '>', mt.type_name)
ELSE mt.type_name
END AS category,
mdi.device_name AS typeName,
mdi.item_type_model AS typeModelName,
mdi.manage_type AS manageType,
mdi.code AS devCode,
SUM(CASE WHEN mdi.ma_status = 2 THEN 1 ELSE 0 END) AS useNum,
1 AS devType,
mdi.type_id AS typeId,
mdi.ma_id AS id
FROM ma_dev_info mdi
LEFT JOIN ma_type mt ON mdi.type_id = mt.type_id
LEFT JOIN ma_type mt1 ON mt.parent_id = mt1.type_id
LEFT JOIN ma_type mt2 ON mt1.parent_id = mt2.type_id
LEFT JOIN ma_type mt3 ON mt2.parent_id = mt3.type_id
LEFT JOIN ma_type mt4 ON mt3.parent_id = mt4.type_id
LEFT JOIN ma_type mt5 ON mt4.parent_id = mt5.type_id
where
mdi.is_active = '1' and mdi.type_id = #{typeId}
<if test="devCode != null and devCode != ''">
and mdi.code = #{devCode}
</if>
LIMIT 1
</select>
<select id="getTypeToolInfo" resultType="com.bonus.material.back.domain.BackCsDeviceDetails">
SELECT CONCAT(tt4.type_name, '>', tt3.type_name, '>', tt2.type_name) as category,
tt1.type_name as typeName,
tt.type_name as typeModelName,
tl.manage_mode as manageType,
IFNULL(tl.tool_code,'/') as devCode,
tl.in_num as useNum,
2 as devType,
tl.type_id as typeId,
tl.id as id
FROM tool_ledger tl
LEFT JOIN tool_type tt ON tl.type_id = tt.type_id
LEFT JOIN tool_type tt1 ON tt.parent_id = tt1.type_id
LEFT JOIN tool_type tt2 ON tt1.parent_id = tt2.type_id
LEFT JOIN tool_type tt3 ON tt2.parent_id = tt3.type_id
LEFT JOIN tool_type tt4 ON tt3.parent_id = tt4.type_id
where
tl.type_id = #{typeId}
<if test="devCode != null and devCode != ''">
and tl.tool_code = #{devCode}
</if>
LIMIT 1
</select>
<select id="getList" resultType="com.bonus.material.back.domain.BackCsDeviceInfo">
SELECT
cd.id AS id,
cd.type AS type,
cd.lease_type AS leaseType,
cd.pro_code AS proCode,
cd.pro_name AS proName,
cd.pro_type AS proType,
cd.voltage_level AS voltageLevel,
cd.use_unit AS useUnit,
cd.pro_province AS proProvince,
cd.pro_city AS proCity,
cd.pro_county AS proCounty,
cd.use_time AS useTime,
cd.use_start_time as useStartTime,
cd.use_end_time as useEndTime,
cd.CODE AS CODE,
cd.review_status AS taskStatus,
cd.create_user AS createBy,
cd.create_time AS createTime,
SUM(IF( cdc.dev_type = '1', cdc.num, 0 )) AS devNum,
SUM(IF( cdc.dev_type = '2', cdc.num, 0 )) AS toolNum
FROM
cs_device_change cd
LEFT JOIN cs_device_change_details cdc ON cd.id = cdc.change_id
WHERE
cdc.del_flag = '0' and cd.type = '1'
<if test="taskStatus != null and taskStatus != ''">
and cd.review_status = #{taskStatus}
</if>
<if test="startTime != null and startTime != '' and endTime != null and endTime != ''">
AND cd.create_time BETWEEN CONCAT(#{startTime}, ' 00:00:00') AND CONCAT(#{endTime}, ' 23:59:59')
</if>
<if test="proName != null and proName != ''">
and cd.pro_name = #{proName}
</if>
<if test="proCode != null and proCode != ''">
and cd.pro_code = #{proCode}
</if>
<if test="useUnit != null and useUnit != ''">
and cd.use_unit = #{useUnit}
</if>
GROUP BY
cd.id
ORDER BY
-- 实现自定义状态排序:审核中(2) > 已驳回(1) > 已通过(0)
CASE cd.review_status
WHEN 2 THEN 1 -- 已驳回 -> 排序值为 0
WHEN 1 THEN 2 -- 已通过 -> 排序值为 2
WHEN 0 THEN 0 -- 待审核 -> 排序值为 1
ELSE 3 -- 其他状态排在最后
END ASC,
-- 按申请时间降序排序(后申请的在前)
cd.create_time
DESC
</select>
</mapper>