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

550 lines
30 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.index.mapper.IndexMapper">
<select id="getDeviceNum" resultType="java.util.Map">
SELECT IFNULL(toolNum,0) AS toolNum,
IFNULL(maNum,0) AS maNum,
IFNULL(totalSum,0) AS totalSum,
IFNULL(ROUND((toolNum / totalSum) * 100, 2),0) AS toolPercent,
IFNULL(ROUND((maNum / totalSum) * 100, 2),0) AS maPercent
FROM (SELECT ROUND(IFNULL(t1.toolNum,0)) AS toolNum,
ROUND(IFNULL(t2.maNum,0)) AS maNum,
ROUND(IFNULL(t1.toolNum,0)) + ROUND(IFNULL(t2.maNum,0)) AS totalSum
FROM (SELECT SUM(total_num - scrap_num) AS toolNum FROM tool_ledger
<where>
<if test="companyId != null">
and company_id = #{companyId}
</if>
</where>
) t1
CROSS JOIN
(SELECT COUNT(mdi.ma_id) AS maNum
FROM ma_dev_info mdi
INNER JOIN ma_type_view mtv ON mtv.typeId = mdi.type_id
<where>
mdi.is_active = '1'
AND mdi.entry_status = '1'
AND mdi.ma_status != '99'
<if test="companyId != null">
and mdi.on_company = #{companyId}
</if>
</where>
) t2) AS temp
</select>
<select id="getUseDeviceNum" resultType="java.util.Map">
SELECT ROUND(IFNULL(t1.available_num, 0) + IFNULL(t2.available_num, 0)) AS availableNum,
ROUND(IFNULL(t1.in_num, 0) + IFNULL(t2.in_num, 0)) AS inNum,
ROUND(IFNULL(t1.share_num, 0) + IFNULL(t2.share_num, 0)) AS shareNum,
ROUND(IFNULL(t1.repair_num, 0) + IFNULL(t2.repair_num, 0)) AS repairNum,
ROUND(IFNULL(t1.scrap_num, 0) + IFNULL(t2.scrap_num, 0)) AS scrapNum
FROM (SELECT IFNULL(SUM(available_num), 0) AS available_num,
IFNULL(SUM(in_num), 0) AS in_num,
IFNULL(SUM(share_num), 0) AS share_num,
IFNULL(SUM(repair_num), 0) AS repair_num,
IFNULL(SUM(scrap_num), 0) AS scrap_num
FROM tool_ledger) t1
CROSS JOIN (SELECT IFNULL(COUNT(CASE WHEN mdi.ma_status = '1' THEN 1 END), 0) AS available_num,
IFNULL(COUNT(CASE WHEN mdi.ma_status = '2' THEN 1 END), 0) AS in_num,
IFNULL(COUNT(CASE WHEN mdi.ma_status = '3' THEN 1 END), 0) AS share_num,
IFNULL(COUNT(CASE WHEN mdi.ma_status = '4' THEN 1 END), 0) AS repair_num,
IFNULL(COUNT(CASE WHEN mdi.ma_status = '5' THEN 1 END), 0) AS scrap_num
FROM ma_dev_info mdi
INNER JOIN ma_type_view mtv ON mtv.typeId = mdi.type_id
WHERE mdi.is_active = '1'
AND mdi.entry_status = '1') t2;
</select>
<select id="getReal" resultType="java.util.Map">
-- 合并申请记录和审核记录,按时间降序排序
SELECT t.applyTime,
t.applyUser,
t.businessName,
t.statusType,
t.deptAbbreviation
FROM (
-- 子查询1申请记录状态为0的当日申请
SELECT DATE_FORMAT(bap.apply_time, '%Y-%m-%d %H:%i:%s') AS applyTime,
IFNULL(su.nick_name, '未知用户') AS applyUser,
CASE bap.business_type
WHEN 'EQUIPMENT_SCRAP' THEN '设备报废'
WHEN 'EQUIPMENT_REPAIR' THEN '设备维修'
WHEN 'EQUIPMENT_RETURN' THEN '设备退库'
WHEN 'EQUIPMENT_OUT' THEN '设备出库'
ELSE '未知业务类型'
END AS businessName,
'申请' AS statusType,
sd.dept_abbreviation AS deptAbbreviation
FROM bm_approval_instance bap
LEFT JOIN sys_user su ON bap.apply_user_id = su.user_id
LEFT JOIN sys_dept sd ON su.dept_id = sd.dept_id
WHERE
-- 筛选当日的申请时间CURDATE() 是当日0点小于次日0点
bap.apply_time &gt;= CURDATE()
AND bap.apply_time &lt; DATE_ADD(CURDATE(), INTERVAL 1 DAY)
UNION ALL
-- 子查询2审核记录关联申请实例获取业务类型
SELECT DATE_FORMAT(bar.create_time, '%Y-%m-%d %H:%i:%s') AS applyTime,
IFNULL(su.nick_name, '系统') AS applyUser, -- 审核人作为用户维度
CASE bap.business_type
WHEN 'EQUIPMENT_SCRAP' THEN '设备报废'
WHEN 'EQUIPMENT_REPAIR' THEN '设备维修'
WHEN 'EQUIPMENT_RETURN' THEN '设备退库'
WHEN 'EQUIPMENT_OUT' THEN '设备出库'
ELSE '未知业务类型'
END AS businessName,
'审核' AS statusType,
sd.dept_abbreviation AS deptAbbreviation
FROM bm_approval_record bar
LEFT JOIN bm_approval_instance bap ON bap.id = bar.instance_id
LEFT JOIN sys_user su ON bar.approver_id = su.user_id
LEFT JOIN sys_dept sd ON su.dept_id = sd.dept_id
-- 可选:添加审核记录的时间筛选(与申请记录一致,筛选当日的审核记录)
WHERE bar.create_time &gt;= CURDATE()
AND bar.create_time &lt; DATE_ADD(CURDATE(), INTERVAL 1 DAY)) t
-- 统一按时间降序排序(申请+审核记录一起排序)
ORDER BY t.applyTime DESC;
</select>
<select id="getDeviceByDept" resultType="java.util.Map">
SELECT
sd.dept_id AS companyId,
sd.dept_abbreviation AS companyName, -- 公司名称
-- 工具数量无数据则为0取整
ROUND(IFNULL(SUM(temp.toolNum), 0)) AS toolNum,
-- 设备数量无数据则为0取整
ROUND(IFNULL(SUM(temp.maNum), 0)) AS maNum,
-- 设备成本无数据则为0保留小数
IFNULL(SUM(temp.maCost), 0) AS maCost,
-- 工具成本无数据则为0保留小数
IFNULL(SUM(temp.toolCost), 0) AS toolCost,
-- 新增manage_mode=0的工具有效数量总和无数据则为0
IFNULL(SUM(temp.toolCodeNum), 0) AS toolCodeNum,
-- 新增manage_mode=1的工具有效数量总和无数据则为0
IFNULL(SUM(temp.toolNoCodeNum), 0) AS toolNoCodeNum
FROM sys_dept sd -- 所有公司的主表
LEFT JOIN (
-- 子查询:合并工具和设备的公司统计数据
SELECT company_id,
SUM(toolNum) AS toolNum,
SUM(maNum) AS maNum,
SUM(maCost) AS maCost,
SUM(toolCost) AS toolCost,
SUM(toolCodeNum) AS toolCodeNum, -- 合并工具编码数量统计值
SUM(toolNoCodeNum) AS toolNoCodeNum -- 合并无工具编码数量统计值
FROM (
-- 工具台账的公司统计:核心统计工具相关数据
SELECT company_id,
SUM(total_num - scrap_num) AS toolNum, -- 工具总数量
-- 工具成本:(总数量-报废数量)*原始成本处理NULL
SUM((total_num - scrap_num) * IFNULL(origin_cost, 0)) AS toolCost,
-- 统计manage_mode=0的工具有效数量total_num - scrap_num
SUM(CASE WHEN manage_mode = 0 THEN (total_num - scrap_num) ELSE 0 END) AS toolCodeNum,
-- 统计manage_mode=1的工具有效数量
SUM(CASE WHEN manage_mode = 1 THEN (total_num - scrap_num) ELSE 0 END) AS toolNoCodeNum,
0 AS maNum, -- 设备数量默认0字段对齐
0 AS maCost -- 设备成本默认0字段对齐
FROM tool_ledger
GROUP BY company_id
UNION ALL
-- 设备信息的公司统计核心统计设备相关数据工具相关字段默认0
SELECT on_company AS company_id,
0 AS toolNum, -- 工具数量默认0
0 AS toolCost, -- 工具成本默认0
0 AS toolCodeNum, -- 工具编码数量默认0字段对齐
0 AS toolNoCodeNum, -- 无工具编码数量默认0字段对齐
COUNT(mdi.ma_id) AS maNum, -- 设备总数量
-- 设备成本采购价求和处理NULL
SUM(IFNULL(mdi.buy_price, 0)) AS maCost
FROM ma_dev_info mdi
INNER JOIN ma_type_view mtv ON mtv.typeId = mdi.type_id
WHERE mdi.is_active = '1'
AND mdi.entry_status = '1'
AND mdi.ma_status != '99' -- 排除状态为99的设备
GROUP BY on_company) t
-- 按公司ID合并数据避免同一公司多条记录
GROUP BY company_id) temp ON sd.dept_id = temp.company_id -- 公司ID关联
WHERE sd.is_show = '1'
-- 按公司ID分组确保每个公司只显示一行
GROUP BY sd.dept_id,
sd.dept_name
-- 核心修改按maNum排序DESC降序/ASC升序默认ASC
-- 推荐降序:设备数量多的公司排在前面
ORDER BY maNum DESC, -- 优先按设备数量排序
sd.dept_id ASC; -- 设备数量相同时按公司ID排序可选保证排序稳定性
</select>
<select id="getMaQc" resultType="java.util.Map">
SELECT
-- 一、装备使用年限相关统计
IFNULL(t1.overdue_num,0)AS useYearOverdueNum, -- 使用年限已超期数量
IFNULL(t1.expire_month_num,0) AS useYearExpireMonthNum, -- 使用年限一月内超期数量
-- 二、装备维保检验日期相关统计
IFNULL(t2.expire_month_num,0) AS maintainExpireMonthNum, -- 维保日期一月内到期数量
IFNULL(t2.overdue_num,0) AS maintainOverdueNum -- 维保日期已超期数量
FROM
-- 子查询1装备使用年限超期统计
(
SELECT
SUM(CASE WHEN t.expire_type = '已超期' THEN 1 ELSE 0 END) AS overdue_num,
SUM(CASE WHEN t.expire_type = '一月内超期' THEN 1 ELSE 0 END) AS expire_month_num
FROM (
SELECT
mdi.ma_id,
CASE
WHEN ROUND(TIMESTAMPDIFF(DAY, mdi.production_date, CURDATE()) / 365.25, 1) >= mdi.max_working_hours THEN '已超期'
WHEN (mdi.max_working_hours - ROUND(TIMESTAMPDIFF(DAY, mdi.production_date, CURDATE()) / 365.25, 1))
&lt;=
1 THEN '一月内超期'
ELSE '正常'
END AS expire_type
FROM
ma_dev_info mdi
INNER JOIN ma_type_view mtv ON mtv.typeId = mdi.type_id
<where>
mdi.is_active = '1'
AND mdi.entry_status = '1'
AND mdi.ma_status != '99'
AND mdi.production_date IS NOT NULL
<if test="companyId != null">
and mdi.on_company = #{companyId}
</if>
</where>
) t
) t1
-- 笛卡尔积关联:两个单一行的统计结果合并为一行
CROSS JOIN
-- 子查询2装备维保检验日期超期统计
(
SELECT
COUNT(CASE
WHEN mdq.next_check_time &gt;= CURRENT_DATE()
AND mdq.next_check_time &lt;= DATE_ADD(CURRENT_DATE(), INTERVAL 1 MONTH)
THEN 1
END) AS expire_month_num,
COUNT(CASE
WHEN mdq.next_check_time &lt; CURRENT_DATE()
THEN 1
END) AS overdue_num
FROM
ma_dev_info mdi
LEFT JOIN (
SELECT
ma_id,
MAX(next_check_time) AS next_check_time
FROM ma_dev_qc
GROUP BY ma_id
) mdq ON mdi.ma_id = mdq.ma_id
<where>
mdi.is_active = '1'
AND mdi.entry_status = '1'
AND mdi.ma_status != '99'
<if test="companyId != null">
and mdi.on_company = #{companyId}
</if>
</where>
) t2;
</select>
<select id="getDeviceNumByMonth" resultType="java.util.Map">
SELECT
-- 自用相关统计
IFNULL(SUM(CASE WHEN cdc.type = '2' AND cdc.review_status = 2 THEN cdcd.real_num ELSE 0 END), 0) AS selfUseApplyNum, -- 自用申请数量
IFNULL(SUM(CASE WHEN cdc.type = '2' AND cdc.review_status = 2 AND cdcd.dev_type = '1' THEN cdcd.real_num ELSE 0 END), 0) AS selfUseOutNum, -- 自用出库数量
IFNULL(SUM(CASE WHEN cdc.type = '2' AND cdc.review_status = 2 AND cdcd.dev_type = '2' THEN cdcd.real_num ELSE 0 END), 0) AS selfUseAuditNum, -- 自用审核数量
-- 退库相关统计
IFNULL(SUM(CASE WHEN cdc.type = '1' AND cdc.review_status = 2 THEN cdcd.num ELSE 0 END), 0) AS returnApplyNum, -- 退库申请数量
IFNULL(SUM(CASE WHEN cdc.type = '1' AND cdc.review_status = 2 AND cdcd.dev_type = '1' THEN cdcd.num ELSE 0 END), 0) AS returnAuditApplyNum, -- 退库审核数量
IFNULL(SUM(CASE WHEN cdc.type = '1' AND cdc.review_status = 2 AND cdcd.dev_type = '2' THEN cdcd.num ELSE 0 END), 0) AS returnAuditRepairNum, -- 退库维修数量
IFNULL(SUM(CASE WHEN cdc.type = '1' AND cdc.review_status = 2 THEN (cdcd.num - cdcd.real_num) ELSE 0 END), 0) AS returnAuditStoreNum, -- 退库入库数量
-- 维修相关统计
IFNULL(SUM(CASE WHEN cdc.type = '4' AND cdc.review_status != 2 THEN cdcd.num ELSE 0 END), 0) AS repairPendingNum, -- 待维修数量
-- 维修退役数量类型4退役+类型3审核通过
IFNULL(SUM(CASE WHEN cdc.type = '4' AND cdc.review_status = 2 AND cdcd.is_scrap = '1' THEN cdcd.real_num ELSE 0 END), 0)
+ IFNULL(SUM(CASE WHEN cdc.type = '3' AND cdc.review_status = 2 THEN cdcd.real_num ELSE 0 END), 0) AS repairRetireNum,
IFNULL(SUM(CASE WHEN cdc.type = '4' AND cdc.review_status = 2 AND cdcd.is_scrap = '0' THEN cdcd.real_num ELSE 0 END), 0) AS repairQualifiedNum, -- 维修合格数量
-- 入库数量原独立子查询改为LEFT JOIN避免多行返回错误
IFNULL(warehouse_stats.total_num, 0) AS warehousingNum
FROM
cs_device_change cdc
INNER JOIN cs_device_change_details cdcd
ON cdcd.change_id = cdc.id
AND cdcd.del_flag = '0' -- 子表未删除
-- 关联入库统计子查询改为JOIN确保单行返回
LEFT JOIN (
SELECT
-- 若需按company_id分组需添加GROUP BY su.dept_id
COALESCE(SUM(ma_detail.maNum), 0) + COALESCE(SUM(tool_detail.toolNum), 0) AS total_num
-- , su.dept_id -- 如需按公司筛选,保留该字段
FROM
bm_warehousing bw
LEFT JOIN sys_user su
ON su.user_id = bw.user_id
LEFT JOIN (
SELECT cs_id, COUNT(1) AS maNum
FROM ma_apply_details
GROUP BY cs_id
) ma_detail
ON ma_detail.cs_id = bw.order_id
LEFT JOIN (
SELECT apply_id, SUM(apply_num) AS toolNum
FROM tool_apply_details
WHERE del_flag = '0'
GROUP BY apply_id
) tool_detail
ON tool_detail.apply_id = bw.apply_id
WHERE
bw.`status` = 2
AND DATE_FORMAT(bw.create_time, '%Y-%m') = DATE_FORMAT(CURDATE(), '%Y-%m')
<if test="companyId != null">
AND su.dept_id = #{companyId}
</if>
) warehouse_stats ON 1=1
WHERE
cdc.del_flag = '0'
AND DATE_FORMAT(cdc.create_time, '%Y-%m') = DATE_FORMAT(CURDATE(), '%Y-%m')
<if test="companyId != null">
AND cdc.company_id = #{companyId}
</if>
</select>
<!-- MySQL版本使用MyBatis的foreach循环拼接OR条件 -->
<select id="getApprover" resultType="java.util.Map">
SELECT
cdc.id AS id,
cdc.code AS code,
DATE_FORMAT(cdc.create_time, '%Y-%m-%d %H:%i:%s') AS createTime,
CASE bai.business_type
WHEN 'EQUIPMENT_SCRAP' THEN '设备退役'
WHEN 'EQUIPMENT_REPAIR' THEN '设备维修'
WHEN 'EQUIPMENT_RETURN' THEN '设备退库'
WHEN 'EQUIPMENT_OUT' THEN '设备出库'
ELSE '未知业务类型'
END AS businessName
FROM
bm_approval_instance bai
LEFT JOIN bm_approval_node ban ON ban.id = bai.current_node_id
LEFT JOIN cs_device_change cdc ON bai.business_id = cdc.id
WHERE
ban.auto_pass = '0'
AND bai.STATUS = '1'
AND cdc.id IS NOT NULL
<!-- 核心二选一场景分别处理userId/roles无OR拼接 -->
<choose>
<!-- 场景1仅userId有值审批人类型为1用户 -->
<when test="userId != null and userId != ''">
AND ban.approver_type = '1'
AND FIND_IN_SET(#{userId}, ban.approver_ids)
</when>
<!-- 场景2仅roles有值审批人类型为2角色 -->
<when test="roles != null and roles.size() > 0">
AND ban.approver_type = '2'
AND (
<foreach collection="roles" item="role" separator="OR" open="" close="">
FIND_IN_SET(#{role}, ban.approver_ids)
</foreach>
)
</when>
</choose>
</select>
<select id="getShare" resultType="java.util.Map">
SELECT
-- 1. 出售方订单数companyId为空时统计所有否则统计指定公司
IFNULL(SUM(CASE
WHEN #{companyId} IS NULL OR #{companyId} = '' THEN 1
WHEN a.sellerDeptId = #{companyId} THEN 1
ELSE 0
END), 0) AS sellerNum,
-- 2. 购买方订单数companyId为空时统计所有否则统计指定公司
IFNULL(SUM(CASE
WHEN #{companyId} IS NULL OR #{companyId} = '' THEN 1
WHEN a.buyerCompanyName = #{companyId} THEN 1
ELSE 0
END), 0) AS buyerNum,
-- 3. 出售设备总数companyId为空时统计所有否则统计指定公司的设备数
IFNULL(SUM(CASE
WHEN (#{companyId} IS NULL OR #{companyId} = '') AND a.devType = '0' THEN a.equipmentTotalNum
WHEN a.sellerDeptId = #{companyId} and a.devType = '0' THEN a.equipmentTotalNum
ELSE 0
END), 0) AS sellerMaNum,
IFNULL(SUM(CASE
WHEN (#{companyId} IS NULL OR #{companyId} = '') AND a.devType = '1' THEN a.equipmentTotalNum
WHEN a.sellerDeptId = #{companyId} and a.devType = '1' THEN a.equipmentTotalNum
ELSE 0
END), 0) AS sellerToolNum,
IFNULL(SUM(CASE
WHEN (#{companyId} IS NULL OR #{companyId} = '') AND a.devType = '0' THEN a.equipmentTotalNum
WHEN a.buyerCompanyName = #{companyId} and a.devType = '0' THEN a.equipmentTotalNum
ELSE 0
END), 0) AS buyerMaNum,
IFNULL(SUM(CASE
WHEN (#{companyId} IS NULL OR #{companyId} = '') AND a.devType = '1' THEN a.equipmentTotalNum
WHEN a.buyerCompanyName = #{companyId} and a.devType = '1' THEN a.equipmentTotalNum
ELSE 0
END), 0) AS buyerToolNum
FROM (
-- 内层查询:按订单维度统计出售方、购买方、设备总数(原逻辑不变)
SELECT up.dept_id AS sellerDeptId,
moi.buyer_company AS buyerCompanyName,
SUM(hh.num) AS equipmentTotalNum,
hh.devType AS devType
FROM ma_order_details hh
LEFT JOIN ma_order_info moi ON moi.order_id = hh.order_id
LEFT JOIN ma_dev_info mdi ON hh.ma_id = mdi.ma_id
LEFT JOIN sys_dept up ON up.dept_id = mdi.on_company
WHERE DATE_FORMAT(moi.create_time, '%Y-%m') = DATE_FORMAT(CURDATE(), '%Y-%m')
GROUP BY hh.order_id,
up.dept_id,
hh.devType,
moi.buyer_company) a
</select>
<select id="getDeviceByDeptEX" resultType="com.bonus.material.index.domain.CompanyDevToolStatisticsExport">
SELECT sd.dept_abbreviation AS companyName, -- 公司名称
-- 工具数量无数据则为0取整
ROUND(IFNULL(SUM(temp.toolNum), 0)) AS toolNum,
-- 设备数量无数据则为0取整
ROUND(IFNULL(SUM(temp.maNum), 0)) AS maNum,
-- 设备成本无数据则为0保留小数
IFNULL(SUM(temp.maCost), 0) AS maCost,
-- 工具成本无数据则为0保留小数
IFNULL(SUM(temp.toolCost), 0) AS toolCost,
-- 新增manage_mode=0的工具有效数量总和无数据则为0
IFNULL(SUM(temp.toolCodeNum), 0) AS toolCodeNum,
-- 新增manage_mode=1的工具有效数量总和无数据则为0
IFNULL(SUM(temp.toolNoCodeNum), 0) AS toolNoCodeNum
FROM sys_dept sd -- 所有公司的主表
LEFT JOIN (
-- 子查询:合并工具和设备的公司统计数据
SELECT company_id,
SUM(toolNum) AS toolNum,
SUM(maNum) AS maNum,
SUM(maCost) AS maCost,
SUM(toolCost) AS toolCost,
SUM(toolCodeNum) AS toolCodeNum, -- 合并工具编码数量统计值
SUM(toolNoCodeNum) AS toolNoCodeNum -- 合并无工具编码数量统计值
FROM (
-- 工具台账的公司统计:核心统计工具相关数据
SELECT company_id,
SUM(total_num - scrap_num) AS toolNum, -- 工具总数量
-- 工具成本:(总数量-报废数量)*原始成本处理NULL
SUM((total_num - scrap_num) * IFNULL(origin_cost, 0)) AS toolCost,
-- 统计manage_mode=0的工具有效数量total_num - scrap_num
SUM(CASE WHEN manage_mode = 0 THEN (total_num - scrap_num) ELSE 0 END) AS toolCodeNum,
-- 统计manage_mode=1的工具有效数量
SUM(CASE WHEN manage_mode = 1 THEN (total_num - scrap_num) ELSE 0 END) AS toolNoCodeNum,
0 AS maNum, -- 设备数量默认0字段对齐
0 AS maCost -- 设备成本默认0字段对齐
FROM tool_ledger
GROUP BY company_id
UNION ALL
-- 设备信息的公司统计核心统计设备相关数据工具相关字段默认0
SELECT on_company AS company_id,
0 AS toolNum, -- 工具数量默认0
0 AS toolCost, -- 工具成本默认0
0 AS toolCodeNum, -- 工具编码数量默认0字段对齐
0 AS toolNoCodeNum, -- 无工具编码数量默认0字段对齐
COUNT(mdi.ma_id) AS maNum, -- 设备总数量
-- 设备成本采购价求和处理NULL
SUM(IFNULL(mdi.buy_price, 0)) AS maCost
FROM ma_dev_info mdi
INNER JOIN ma_type_view mtv ON mtv.typeId = mdi.type_id
WHERE mdi.is_active = '1'
AND mdi.entry_status = '1'
AND mdi.ma_status != '99' -- 排除状态为99的设备
GROUP BY on_company) t
-- 按公司ID合并数据避免同一公司多条记录
GROUP BY company_id) temp ON sd.dept_id = temp.company_id -- 公司ID关联
WHERE sd.dept_abbreviation is NOT null
-- 按公司ID分组确保每个公司只显示一行
GROUP BY sd.dept_id,
sd.dept_name
-- 核心修改按maNum排序DESC降序/ASC升序默认ASC
-- 推荐降序:设备数量多的公司排在前面
ORDER BY maNum DESC, -- 优先按设备数量排序
sd.dept_id ASC; -- 设备数量相同时按公司ID排序可选保证排序稳定性
</select>
<select id="listXlsx" resultType="com.bonus.material.index.domain.MaDevInfoXlsxExport">
select mdi.ma_id AS maId,
sd.dept_name AS propertyUnit,
mtv.proType AS major,
CONCAT_WS('>', mtv.mainGx, mtv.childGx) AS subProcess,
CONCAT_WS('>',mtv.devCategory, mtv.devSubcategory) AS subCategory,
mdi.device_name AS name,
mdi.item_type_model As specificationModel,
mdi.code AS code,
mdi.identify_code AS originalCode,
CASE mdi.ma_status
WHEN 1 THEN '在库'
WHEN 2 THEN '自用'
WHEN 3 THEN '共享'
WHEN 5 THEN '维修'
WHEN 99 THEN '退役'
ELSE '未知状态'
END AS status,
TIMESTAMPDIFF(YEAR, mdi.production_date, CURDATE()) AS serviceLife,
mdi.unit AS unit,
mdi.buy_price AS originalValue,
ms.supplier_name AS manufacturer,
DATE_FORMAT(mdi.production_date, '%Y-%m-%d') AS productionDate,
mdi.max_working_hours AS maxServiceLifeYears,
su.nick_name AS creator,
mdi.create_time AS createTime
from ma_dev_info mdi
INNER JOIN ma_type_view mtv ON mtv.typeId = mdi.type_id
LEFT JOIN sys_dept sd ON sd.dept_id = mdi.on_company
LEFT JOIN sys_user su ON su.user_id = mdi.creator
LEFT JOIN ma_supplier ms ON ms.supplier_id = mdi.supplier_id
<where>
mdi.is_active = '1' and mdi.entry_status = '1'
</where>
</select>
<select id="listToolLedgerEntity" resultType="com.bonus.material.index.domain.ToolLedgerEntityExport">
SELECT IFNULL(tl.tool_code, '-') AS code,
tt.type_name AS typeName,
tt1.type_name AS parentTypeName,-- 1级父节点名称
tt2.type_name AS grandparentTypeName,-- 2级父节点名称
tt3.type_name AS greatGrandparentName,-- 3级父节点名称
tt4.type_name AS fourthParentName,
CASE
tl.manage_mode
WHEN 0 THEN
'编码管理'
WHEN 1 THEN
'数量管理'
ELSE '未知状态'
END AS manageMode,
COALESCE(tl.available_num, 0) AS availableNum,-- 在库
COALESCE(tl.in_num, 0) AS inNum,-- 自用
COALESCE(tl.share_num, 0) AS shareNum,-- 共享
COALESCE(tl.repair_num, 0) AS repairNum,-- 维修
COALESCE(tl.scrap_num, 0) AS scrapNum,-- 报废
(tl.total_num - tl.scrap_num) * origin_cost AS totalNum, -- 总数
su.nick_name AS creator,
tl.create_time AS createTime,
sd.dept_name AS propertyUnit
FROM tool_ledger tl -- 关联1级父节点直接父节点
INNER JOIN tool_type tt ON tt.type_id = tl.type_id
LEFT JOIN sys_dept sd ON sd.dept_id = tl.company_id
LEFT JOIN sys_user su ON tt.create_by = su.user_id
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'
ORDER BY tl.manage_mode, tl.create_time
DESC
</select>
</mapper>