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

395 lines
19 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.toolLedger.mapper.ToolLedgerMapper">
<insert id="add" parameterType="com.bonus.material.toolLedger.domain.ToolLedgerEntity"
useGeneratedKeys="true" keyProperty="id" keyColumn="id">
INSERT INTO tool_ledger
<!--
trim 标签核心作用:
1. prefix="(":给整体加前缀 "("
2. suffix=")":给整体加后缀 ")"
3. suffixOverrides=",":移除末尾多余的逗号
4. 内部 <if> 正常判断,无需担心逗号结尾
-->
<trim prefix="(" suffix=")" suffixOverrides=",">
<if test="toolCode != null and toolCode != ''">tool_code,</if>
<if test="typeId != null">type_id,</if>
<if test="manageMode != null">manage_mode,</if>
<if test="originCost != null">origin_cost,</if>
<if test="identifyCode != null">identify_code,</if>
<if test="totalNum != null">total_num,</if>
<if test="availableNum != null">available_num,</if>
<if test="inNum != null">in_num,</if>
<if test="repairNum != null">repair_num,</if>
<if test="scrapNum != null">scrap_num,</if>
<if test="supplierId != null">supplier_id,</if>
<if test="purchaseDate != null">purchase_date,</if>
<if test="productionDate != null">production_date,</if>
<if test="lastCheckDate != null">last_check_date,</if>
<if test="nextCheckDate != null">next_check_date,</if>
<if test="status != null and status != ''">status,</if>
<if test="upDownStatus != null and upDownStatus != ''">up_down_status,</if>
<if test="companyId != null">company_id,</if>
<if test="remark != null and remark != ''">remark,</if>
<!-- 兜底:至少保留一个必填字段(根据你的业务,选一个非空字段,比如 typeId -->
<if test="typeId == null">type_id</if> <!-- 避免字段列表为空,若 typeId 是必填则可省略此兜底 -->
</trim>
VALUES
<trim prefix="(" suffix=")" suffixOverrides=",">
<if test="toolCode != null and toolCode != ''">#{toolCode},</if>
<if test="typeId != null">#{typeId},</if>
<if test="manageMode != null">#{manageMode},</if>
<if test="originCost != null">#{originCost},</if>
<if test="identifyCode != null">#{identifyCode},</if>
<if test="totalNum != null">#{totalNum},</if>
<if test="availableNum != null">#{availableNum},</if>
<if test="inNum != null">#{inNum},</if>
<if test="repairNum != null">#{repairNum},</if>
<if test="scrapNum != null">#{scrapNum},</if>
<if test="supplierId != null">#{supplierId},</if>
<if test="purchaseDate != null">#{purchaseDate},</if>
<if test="productionDate != null">#{productionDate},</if>
<if test="lastCheckDate != null">#{lastCheckDate},</if>
<if test="nextCheckDate != null">#{nextCheckDate},</if>
<if test="status != null and status != ''">#{status},</if>
<if test="upDownStatus != null and upDownStatus != ''">#{upDownStatus},</if>
<if test="companyId != null">#{companyId},</if>
<if test="remark != null and remark != ''">#{remark},</if>
<!-- 对应上面的兜底字段,确保参数列表和字段列表数量一致 -->
<if test="typeId == null">null</if>
</trim>
</insert>
<select id="list" resultType="com.bonus.material.toolLedger.domain.ToolLedgerAllEntity">
SELECT
tt.type_id AS typeId,
tt.type_name AS typeName,
tt.unit_name AS unitName,
tt.manage_type AS manageMode,
tt1.type_name AS parentTypeName, -- 1级父节点名称
tt2.type_name AS grandparentTypeName, -- 2级父节点名称
tt3.type_name AS greatGrandparentName, -- 3级父节点名称
tt4.type_name AS fourthParentName, -- 4级父节点名称
SUM(COALESCE ( tl.available_num, 0 )) AS availableNum, -- 在库
SUM(COALESCE ( tl.in_num, 0 )) AS inNum, -- 自用
SUM(COALESCE ( tl.share_num, 0 )) AS shareNum, -- 共享
SUM(COALESCE ( tl.repair_num, 0 )) AS repairNum, -- 维修
SUM(COALESCE ( tl.scrap_num, 0 )) AS scrapNum, -- 报废
SUM(COALESCE ( tl.total_num - tl.scrap_num, 0 )) AS totalNum -- 总数
FROM
tool_type tt
LEFT JOIN tool_ledger tl ON tl.type_id = tt.type_id
-- 关联1级父节点直接父节点
INNER JOIN tool_type tt1 ON tt.parent_id = tt1.type_id
-- 关联2级父节点祖父节点
INNER JOIN tool_type tt2 ON tt1.parent_id = tt2.type_id
-- 关联3级父节点曾祖父节点
INNER JOIN tool_type tt3 ON tt2.parent_id = tt3.type_id
-- 关联4级父节点
INNER JOIN tool_type tt4 ON tt3.parent_id = tt4.type_id
WHERE
tt.del_flag = '0'
AND tt1.del_flag = '0'
AND tt2.del_flag = '0'
AND tt3.del_flag = '0'
AND tt4.del_flag = '0'
<if test="typeId != null and typeId != ''">
AND (tt1.type_id = #{typeId} or tt2.type_id = #{typeId} or tt3.type_id =
#{typeId} or tt4.type_id =#{typeId})
</if>
<if test="manageMode != null and manageMode != ''">
AND tt.manage_type = #{manageMode}
</if>
<if test="companyId != null">
AND (tl.company_id = #{companyId} OR tl.company_id IS NULL)
</if>
<if test="typeName != null and typeName != ''">
AND tt.type_name LIKE CONCAT('%', #{typeName}, '%')
</if>
GROUP BY tl.type_id
ORDER BY
tl.create_time DESC
</select>
<select id="getByType" resultType="com.bonus.material.toolLedger.domain.ToolLedgerEntity">
SELECT id AS id,
tool_code AS toolCode,
type_id AS typeId,
manage_mode AS manageMode,
origin_cost AS originCost,
total_num AS totalNum,
available_num AS availableNum,
in_num AS inNum,
repair_num AS repairNum,
scrap_num AS scrapNum,
supplier_id AS supplierId,
purchase_date AS purchaseDate,
production_date AS productionDate,
last_check_date AS lastCheckDate,
next_check_date AS nextCheckDate,
status AS status,
up_down_status AS upDownStatus,
company_id AS companyId,
remark AS remark,
create_time AS createTime,
update_time AS updateTime
from tool_ledger
WHERE type_id = #{typeId}
</select>
<select id="getCode" resultType="java.lang.String">
SELECT CONCAT(
'TOOL-', -- 自定义前缀
DATE_FORMAT(CURDATE(), '%Y%m%d'), -- 今日日期格式YYYYMMDD
'-',
LPAD(IFNULL(serial_count, 0) + 1, 4, '0') -- 序号+1补零到3位001, 002...
) AS today_serial_no
FROM (
-- 统计今日已生成的记录数
SELECT IFNULL(COUNT(*), 0) AS serial_count
FROM tool_ledger
WHERE DATE(create_time) = CURDATE()
AND manage_mode = '0') AS count_result;
</select>
<select id="listCode" resultType="com.bonus.material.toolLedger.domain.ToolLedgerEntity">
SELECT
tt.type_id AS typeId,
tt.type_name AS typeName,
tt.unit_name AS unitName,
tt.manage_type AS manageMode,
tt1.type_name AS parentTypeName, -- 1级父节点名称
tt2.type_name AS grandparentTypeName, -- 2级父节点名称
tt3.type_name AS greatGrandparentName, -- 3级父节点名称
tt4.type_name AS fourthParentName, -- 4级父节点名称
tl.id AS id,
tl.tool_code AS toolCode,
tl.manage_mode AS manageMode,
tl.origin_cost AS originCost,
tl.total_num AS totalNum,
tl.available_num AS availableNum,
tl.in_num AS inNum,
tl.repair_num AS repairNum,
tl.scrap_num AS scrapNum,
tl.supplier_id AS supplierId,
ms.supplier_name AS supplierName,
tl.identify_code AS identifyCode,
tl.purchase_date AS purchaseDate,
tl.production_date AS productionDate,
tl.last_check_date AS lastCheckDate,
tl.next_check_date AS nextCheckDate,
tl.status AS status,
tl.up_down_status AS upDownStatus,
tl.company_id AS companyId,
tl.remark AS remark,
tl.fileList AS fileList,
tl.create_time AS createTime,
tl.update_time AS updateTime
FROM
tool_type tt
LEFT JOIN tool_ledger tl ON tl.type_id = tt.type_id
LEFT JOIN ma_supplier ms ON ms.supplier_id = tl.supplier_id
-- 关联1级父节点直接父节点
INNER JOIN tool_type tt1 ON tt.parent_id = tt1.type_id
-- 关联2级父节点祖父节点
INNER JOIN tool_type tt2 ON tt1.parent_id = tt2.type_id
-- 关联3级父节点曾祖父节点
INNER JOIN tool_type tt3 ON tt2.parent_id = tt3.type_id
-- 关联4级父节点
INNER JOIN tool_type tt4 ON tt3.parent_id = tt4.type_id
WHERE
tt.del_flag = '0' and tl.tool_code is not null
AND tt1.del_flag = '0'
AND tt2.del_flag = '0'
AND tt3.del_flag = '0'
AND tt4.del_flag = '0'
<if test="fourthParentId != null and fourthParentId != ''">
AND tt4.type_id =#{fourthParentId}
</if>
<if test="greatGrandparentId != null and greatGrandparentId != ''">
AND tt3.type_id = #{greatGrandparentId}
</if>
<if test="grandparentTypeId != null and grandparentTypeId != ''">
AND tt2.type_id = #{grandparentTypeId}
</if>
<if test="parentTypeId != null and parentTypeId != ''">
AND tt1.type_id = #{parentTypeId}
</if>
<if test="typeName != null and typeName != ''">
AND tt.type_name LIKE CONCAT('%', #{typeName}, '%')
</if>
<if test="toolCode != null and toolCode != ''">
AND tl.tool_code LIKE CONCAT('%', #{toolCode}, '%')
</if>
<if test="companyId != null">
AND (tl.company_id = #{companyId} OR tl.company_id IS NULL)
</if>
ORDER BY
tl.create_time DESC
</select>
<!--
根据类型ID和主键ID更新工具台账支持动态非空字段更新
参数ToolLedgerEntity需包含 typeId 和 id 作为查询条件,其他字段非空则更新)
-->
<update id="updateByTypeAndId" parameterType="com.bonus.material.toolLedger.domain.ToolLedgerEntity">
UPDATE tool_ledger
<set>
<!-- 动态更新仅非空字段才加入SET语句 -->
<if test="toolCode != null and toolCode != ''">tool_code = #{toolCode,jdbcType=VARCHAR},</if>
<if test="manageMode != null">manage_mode = #{manageMode,jdbcType=TINYINT},</if>
<if test="originCost != null">origin_cost = #{originCost,jdbcType=DECIMAL},</if>
<if test="totalNum != null">total_num = #{totalNum,jdbcType=DECIMAL},</if>
<if test="availableNum != null">available_num = #{availableNum,jdbcType=DECIMAL},</if>
<if test="inNum != null">in_num = #{inNum,jdbcType=DECIMAL},</if>
<if test="repairNum != null">repair_num = #{repairNum,jdbcType=DECIMAL},</if>
<if test="scrapNum != null">scrap_num = #{scrapNum,jdbcType=DECIMAL},</if>
<if test="supplierId != null">supplier_id = #{supplierId,jdbcType=INTEGER},</if>
<if test="purchaseDate != null">purchase_date = #{purchaseDate,jdbcType=DATE},</if>
<if test="productionDate != null">production_date = #{productionDate,jdbcType=DATE},</if>
<if test="lastCheckDate != null">last_check_date = #{lastCheckDate,jdbcType=DATE},</if>
<if test="nextCheckDate != null">next_check_date = #{nextCheckDate,jdbcType=DATE},</if>
<if test="status != null and status != ''">status = #{status,jdbcType=CHAR},</if>
<if test="upDownStatus != null and upDownStatus != ''">up_down_status = #{upDownStatus,jdbcType=CHAR},</if>
<if test="companyId != null">company_id = #{companyId,jdbcType=BIGINT},</if>
<if test="remark != null and remark != ''">remark = #{remark,jdbcType=VARCHAR},</if>
<!-- 强制更新时间戳数据库若配置ON UPDATE则可省略 -->
update_time = CURRENT_TIMESTAMP
</set>
WHERE
type_id = #{typeId,jdbcType=BIGINT}
<!-- 必加主键ID避免批量更新同类型所有记录关键 -->
AND id = #{id,jdbcType=BIGINT}
<!-- 可选逻辑删除条件若表有is_deleted字段 -->
<!-- AND is_deleted = 0 -->
</update>
<delete id="delProperties">
delete
from tool_properties
where tool_id = #{toolId}
</delete>
<select id="getProperties" resultType="com.bonus.material.device.domain.vo.DevInfoPropertyVo">
SELECT property_name AS propertyName, property_value AS propertyValue
FROM tool_properties
WHERE tool_id = #{toolId}
</select>
<select id="getToolByTypeId" resultType="com.bonus.material.toolLedger.domain.ToolLedgerEntity">
SELECT a.toolCode,
a.totalNum,
a.typeName,
a.parentTypeName
FROM (
SELECT tl.tool_code AS toolCode,
tl.available_num AS totalNum,
tt.type_name AS typeName,
tt1.type_name AS parentTypeName
FROM tool_ledger tl
INNER JOIN tool_type tt ON tt.type_id = tl.type_id
INNER JOIN tool_type tt1 ON tt1.type_id = tt.parent_id
WHERE tl.status = #{status}
AND tl.type_id = #{typeId}
<if test="companyId != null">
AND (tl.company_id = #{companyId} OR tl.company_id IS NULL)
</if>
) a
<where>
<if test="keyWord != null and keyWord != ''">
AND (
a.toolCode LIKE CONCAT('%', #{keyWord}, '%')
OR a.typeName LIKE CONCAT('%', #{keyWord}, '%')
OR a.parentTypeName LIKE CONCAT('%', #{keyWord}, '%')
)
</if>
</where>
</select>
<select id="getToolByPro" resultType="com.bonus.material.toolLedger.domain.ToolLedgerEntity">
SELECT cdc.pro_name AS proName, -- 工程名称
cdcd.dev_code AS toolCode, -- 工具编码
tt.type_name AS typeName, -- 工具类型名称
tt1.type_name AS parentTypeName,
IFNULL(
SUM(CASE
WHEN cdc.type = '2' AND cdcd.is_finished in ('1', '2') THEN IFNULL(cdcd.real_num, 0)
ELSE 0 END),
0
) - IFNULL(SUM(CASE WHEN cdc.type = '1' THEN IFNULL(cdcd.real_num, 0) ELSE 0 END), 0) -
IFNULL(SUM(CASE WHEN cdc.type = '1' THEN IFNULL(cdcd.num, 0) ELSE 0 END), 0) AS totalNum
FROM cs_device_change_details cdcd
INNER JOIN cs_device_change cdc
ON cdcd.change_id = cdc.id
AND cdc.del_flag = '0'
LEFT JOIN tool_type tt
ON cdcd.dev_type_id = tt.type_id
LEFT JOIN tool_type tt1
ON tt1.type_id = tt.parent_id
WHERE cdcd.dev_type = '2'
AND cdcd.del_flag = '0'
AND cdc.type IN ('1', '2')
AND cdcd.dev_type_id = #{typeId}
AND cdc.lease_type = #{status}
GROUP BY cdc.pro_name, cdc.pro_code, cdcd.dev_code, cdcd.dev_type_id, tt.type_name
HAVING totalNum > 0
ORDER BY cdc.pro_name ASC, cdcd.dev_code ASC
</select>
<select id="getToolByOrder" resultType="com.bonus.material.toolLedger.domain.ToolLedgerEntity">
SELECT
oi.pro_name AS proName,-- 工程名称
tl.tool_code AS toolCode,-- 工具编码
tt.type_name AS typeName,-- 工具类型名称
tt1.type_name AS parentTypeName,
od.real_num AS total_num
FROM
ma_order_details od
LEFT JOIN ma_order_info oi ON oi.order_id = od.order_id
LEFT JOIN tool_ledger tl on tl.id=od.ma_id
LEFT JOIN tool_type tt ON tl.type_id = tt.type_id
LEFT JOIN tool_type tt1 ON tt1.type_id = tt.parent_id
where od.devType=#{status}
AND tl.type_id = #{typeId}
</select>
<insert id="insertDevInfoProperties">
insert into
tool_properties(tool_id, property_name, property_value, create_time)
values
<foreach collection="list" item="item" index="index" separator=",">
(
#{toolId},
#{item.propertyName},
#{item.propertyValue},
now()
)
</foreach>
</insert>
<update id="updateById">
UPDATE tool_ledger
<set>
<!-- 动态更新仅非空字段才加入SET语句 -->
<if test="toolCode != null and toolCode != ''">tool_code = #{toolCode},</if>
<if test="manageMode != null">manage_mode = #{manageMode},</if>
<if test="originCost != null">origin_cost = #{originCost},</if>
<if test="totalNum != null">total_num = #{totalNum},</if>
<if test="availableNum != null">available_num = #{availableNum},</if>
<if test="identifyCode != null">identify_code=#{identifyCode},</if>
<if test="inNum != null">in_num = #{inNum},</if>
<if test="repairNum != null">repair_num = #{repairNum},</if>
<if test="scrapNum != null">scrap_num = #{scrapNum},</if>
<if test="supplierId != null">supplier_id = #{supplierId},</if>
<if test="purchaseDate != null">purchase_date = #{purchaseDate},</if>
<if test="productionDate != null">production_date = #{productionDate},</if>
<if test="lastCheckDate != null">last_check_date = #{lastCheckDate},</if>
<if test="nextCheckDate != null">next_check_date = #{nextCheckDate},</if>
<if test="status != null and status != ''">status = #{status},</if>
<if test="upDownStatus != null and upDownStatus != ''">up_down_status = #{upDownStatus},</if>
<if test="companyId != null">company_id = #{companyId},</if>
<if test="remark != null and remark != ''">remark = #{remark},</if>
<!-- 强制更新时间戳数据库若配置ON UPDATE则可省略 -->
update_time = CURRENT_TIMESTAMP
</set>
WHERE id = #{id,jdbcType=BIGINT}
</update>
</mapper>