change(mes):优化在制品跟踪报表及工序进度查询性能

-优化 `ProcessProgressVo`,新增产品订单ID、工序进度相关字段(计划数量、完成数量、进度百分比等),  并细化状态描述与时间字段支持。
- 为 `ProdReportMapper` 添加批量获取订单工序进度的方法,避免N+1问题,提升查询效率。
- 重写在制品跟踪报表SQL逻辑,使用CTE优化订单筛选与工序统计,避免全表扫描,提高报表导出性能。
- 报表导出方法更新为使用专用导出VO,确保导出数据格式一致性。
- 更新XML中部分注释和逻辑,增强可读性与维护性。
master
zangch@mesnac.com 3 months ago
parent 50abfb434d
commit ad16b86caa

@ -167,12 +167,18 @@ public class ProdReportController extends BaseController {
}
/**
*
* -
*/
@RepeatSubmit()
@PostMapping("/wipTrackingReport/export")
public void wipTrackingReportExport(@RequestParam(required = false) Map hashMap, HttpServletResponse response) {
// 获取报表数据
List<WipTrackingReportVo> list = prodReportService.wipTrackingReportList(hashMap);
ExcelUtil.exportExcel(list, "在制品跟踪报表", WipTrackingReportVo.class, response);
// 转换为导出专用VO
List<WipTrackingReportExportVo> exportList = prodReportService.convertToExportVo(list);
// 使用EasyExcel导出保持与页面相同的样式和数据
ExcelUtil.exportExcel(exportList, "在制品跟踪报表", WipTrackingReportExportVo.class, response);
}
}

@ -4,9 +4,11 @@ import lombok.Data;
import java.io.Serial;
import java.io.Serializable;
import java.math.BigDecimal;
import java.time.LocalDateTime;
/**
* VO
* VO -
*
* @author Yinq
* @date 2025-01-25
@ -17,6 +19,11 @@ public class ProcessProgressVo implements Serializable {
@Serial
private static final long serialVersionUID = 1L;
/**
* ID
*/
private Long productOrderId;
/**
* ID
*/
@ -33,7 +40,7 @@ public class ProcessProgressVo implements Serializable {
private Integer processOrder;
/**
* 0 1 2 3
* 0 1 2 3
*/
private String planStatus;
@ -43,7 +50,52 @@ public class ProcessProgressVo implements Serializable {
private String statusDesc;
/**
*
* 1 0
*/
private Boolean isCompleted;
private Integer isCompleted;
/**
* 1 0
*/
private Integer isInProgress;
/**
*
*/
private BigDecimal planAmount;
/**
*
*/
private BigDecimal completeAmount;
/**
*
*/
private BigDecimal remainingAmount;
/**
*
*/
private BigDecimal processProgress;
/**
*
*/
private LocalDateTime planBeginTime;
/**
*
*/
private LocalDateTime planEndTime;
/**
*
*/
private LocalDateTime realBeginTime;
/**
*
*/
private LocalDateTime realEndTime;
}

@ -29,6 +29,11 @@ public class WipTrackingReportVo implements Serializable {
*/
private Long productOrderId;
/**
* ID
*/
private Long tenantId;
/**
*
*/

@ -119,7 +119,16 @@ public interface ProdReportMapper {
List<WipTrackingReportVo> wipTrackingReportList(@Param("map") Map hashMap);
/**
*
*
*/
List<ProcessProgressVo> getOrderProcessProgress(@Param("productOrderId") Long productOrderId, @Param("planTableName") String planTableName);
/**
* N+1
* @param productOrderIds ID
* @param planTableName prod_plan_info_2/_3/_4
* @return
*/
List<ProcessProgressVo> getOrdersProcessProgressBatch(@Param("productOrderIds") List<Long> productOrderIds,
@Param("planTableName") String planTableName);
}

@ -216,8 +216,8 @@
<if test="map.beginDate != null and map.beginDate != '' and map.endDate != null and map.endDate != ''">
FORMAT(ppd.create_time, 'yyyy-MM-dd') BETWEEN #{map.beginDate} AND #{map.endDate}
</if>
<!-- <if test="map.processId != null and map.processId != ''">-->
<!-- AND ppi.process_id = #{map.processId}-->
<!-- <if test="map.processId != null and map.processId != ''">
<!-- AND ppi.process_id = #{map.processId}
<!-- </if>-->
<if test="map.machineId != null and map.machineId != ''">
AND ppi.release_id = #{map.machineId}
@ -296,48 +296,18 @@
ORDER BY ppd.real_begin_time DESC, ppi.plan_id DESC
</select>
<!-- 在制品跟踪报表 -->
<!-- 在制品跟踪报表 - 高性能优化版本(进一步优化:限制工序统计范围到已过滤订单,避免全表扫描;使用索引友好时间过滤) -->
<select id="wipTrackingReportList" resultType="org.dromara.mes.domain.vo.WipTrackingReportVo">
SELECT
o.product_order_id AS productOrderId,
o.order_code AS orderCode,
m.material_code AS materialCode,
m.material_name AS materialName,
m.material_spec AS materialSpec,
CAST(o.plan_amount AS DECIMAL(18,2)) AS planAmount,
CAST(ISNULL(o.plan_amount,0) - ISNULL(o.complete_amount,0) AS DECIMAL(18,2)) AS wipAmount,
CAST(ISNULL(o.complete_amount,0) AS DECIMAL(18,2)) AS completeAmount,
o.plan_begin_time AS planBeginTime,
o.real_begin_time AS realBeginTime,
o.plan_end_time AS planEndTime,
GETDATE() AS currentTime,
'3道' AS totalProcessCount,
'在制工序' AS wipProcesses,
'剩余工序' AS remainingProcesses,
CONCAT(
CAST(
CASE WHEN o.plan_amount > 0
THEN (CAST(ISNULL(o.complete_amount,0) AS DECIMAL(18,6)) / CAST(o.plan_amount AS DECIMAL(18,6))) * 100
ELSE 0 END
AS DECIMAL(10,2)), '%'
) AS overallProgress,
CASE
WHEN o.plan_end_time IS NOT NULL AND GETDATE() > o.plan_end_time AND ISNULL(o.complete_amount,0) &lt; o.plan_amount
THEN '延期'
ELSE '正常'
END AS progressStatus,
3 AS totalProcessCountNum,
CAST(0 AS DECIMAL(18,2)) AS wipWeightedSum,
CAST(
CASE WHEN o.plan_amount > 0
THEN (CAST(ISNULL(o.complete_amount,0) AS DECIMAL(18,6)) / CAST(o.plan_amount AS DECIMAL(18,6))) * 100
ELSE 0 END
AS DECIMAL(10,2)) AS overallProgressNum
FROM prod_order_info o
JOIN base_material_info m ON m.material_id = o.material_id
<where>
WITH Orders AS (
-- 先根据筛选条件提取订单范围,避免后续工序统计对全库扫描(索引友好)
SELECT o.product_order_id, o.tenant_id
FROM prod_order_info o
INNER JOIN base_material_info m ON m.material_id = o.material_id
WHERE m.del_flag = '0'
<if test="map.beginDate != null and map.beginDate != '' and map.endDate != null and map.endDate != ''">
AND FORMAT(o.plan_begin_time, 'yyyy-MM-dd') BETWEEN #{map.beginDate} AND #{map.endDate}
-- 时间范围过滤:避免对列使用函数,保持索引可用
AND o.plan_begin_time &gt;= CAST(#{map.beginDate} AS DATETIME)
AND o.plan_begin_time &lt; DATEADD(day, 1, CAST(#{map.endDate} AS DATETIME))
</if>
<if test="map.orderCode != null and map.orderCode != ''">
AND o.order_code LIKE CONCAT('%', #{map.orderCode}, '%')
@ -348,6 +318,139 @@
<if test="map.materialCode != null and map.materialCode != ''">
AND m.material_code LIKE CONCAT('%', #{map.materialCode}, '%')
</if>
),
ProcessStats AS (
-- 统计每个订单的工序进度信息仅统计已过滤的订单范围UNION ALL 提升性能)
SELECT
ap.product_order_id,
ap.tenant_id,
COUNT(*) AS totalProcessCount,
SUM(CASE WHEN ap.plan_status = '3' THEN 1 ELSE 0 END) AS completedProcessCount,
SUM(CASE WHEN ap.plan_status = '2' THEN 1 ELSE 0 END) AS wipProcessCount,
MAX(CASE WHEN ap.plan_status = '3' THEN ap.process_order ELSE 0 END) AS maxCompletedOrder,
-- 在制工序名称(进行中的工序)
STRING_AGG(CASE WHEN ap.plan_status = '2' THEN ap.process_name END, ',') AS wipProcessNames,
-- 剩余工序名称(未派工和已派工但未开始的工序)
STRING_AGG(CASE WHEN ap.plan_status IN ('0','1') THEN ap.process_name END, ',') AS remainingProcessNames,
-- 在制品数量加权计算
SUM(CASE WHEN ap.plan_status = '2' THEN ISNULL(ap.plan_amount - ap.complete_amount, 0) * ap.process_order ELSE 0 END) AS wipWeightedSum
FROM (
-- 半制品工序prod_plan_info_2
SELECT
p2.product_order_id,
p2.tenant_id,
p2.process_id,
p2.process_order,
p2.plan_status,
p2.plan_amount,
p2.complete_amount,
pr2.process_name
FROM prod_plan_info_2 p2
LEFT JOIN prod_base_process_info pr2 ON pr2.process_id = p2.process_id
INNER JOIN Orders ord ON ord.product_order_id = p2.product_order_id AND ord.tenant_id = p2.tenant_id
WHERE p2.product_order_id IS NOT NULL
UNION ALL
-- 成型工序prod_plan_info_3
SELECT
p3.product_order_id,
p3.tenant_id,
p3.process_id,
p3.process_order,
p3.plan_status,
p3.plan_amount,
p3.complete_amount,
pr3.process_name
FROM prod_plan_info_3 p3
LEFT JOIN prod_base_process_info pr3 ON pr3.process_id = p3.process_id
INNER JOIN Orders ord ON ord.product_order_id = p3.product_order_id AND ord.tenant_id = p3.tenant_id
WHERE p3.product_order_id IS NOT NULL
UNION ALL
-- 硫化工序prod_plan_info_4
SELECT
p4.product_order_id,
p4.tenant_id,
p4.process_id,
p4.process_order,
p4.plan_status,
p4.plan_amount,
p4.complete_amount,
pr4.process_name
FROM prod_plan_info_4 p4
LEFT JOIN prod_base_process_info pr4 ON pr4.process_id = p4.process_id
INNER JOIN Orders ord ON ord.product_order_id = p4.product_order_id AND ord.tenant_id = p4.tenant_id
WHERE p4.product_order_id IS NOT NULL
) AS ap
GROUP BY ap.product_order_id, ap.tenant_id
)
SELECT
o.product_order_id AS productOrderId,
o.order_code AS orderCode,
m.material_code AS materialCode,
m.material_name AS materialName,
ISNULL(m.material_spec, '') AS materialSpec,
CAST(o.plan_amount AS DECIMAL(18,2)) AS planAmount,
CAST(ISNULL(o.plan_amount,0) - ISNULL(o.complete_amount,0) AS DECIMAL(18,2)) AS wipAmount,
CAST(ISNULL(o.complete_amount,0) AS DECIMAL(18,2)) AS completeAmount,
o.plan_begin_time AS planBeginTime,
o.real_begin_time AS realBeginTime,
o.plan_end_time AS planEndTime,
GETDATE() AS currentTime,
CAST(ISNULL(ps.totalProcessCount, 0) AS VARCHAR(10)) + '道' AS totalProcessCount,
-- 清理工序名称中的多余逗号和空格
LTRIM(RTRIM(REPLACE(REPLACE(ISNULL(ps.wipProcessNames, ''), ',,', ','), ',', ','))) AS wipProcesses,
LTRIM(RTRIM(REPLACE(REPLACE(ISNULL(ps.remainingProcessNames, ''), ',,', ','), ',', ','))) AS remainingProcesses,
-- 整体进度计算:已完成数量占比 + 在制品进度占比
CONCAT(
CAST(
CASE
WHEN o.plan_amount > 0 AND ps.totalProcessCount > 0
THEN (
-- 已完成数量占比
(CAST(ISNULL(o.complete_amount,0) AS DECIMAL(18,6)) / CAST(o.plan_amount AS DECIMAL(18,6))) * 100 +
-- 在制品进度占比:(在制数量/计划总数量) * (当前工序位置/总工序数)
(CAST(ISNULL(o.plan_amount - o.complete_amount,0) AS DECIMAL(18,6)) / CAST(o.plan_amount AS DECIMAL(18,6))) *
(CAST(ISNULL(ps.maxCompletedOrder, 0) + 1 AS DECIMAL(18,6)) / CAST(ps.totalProcessCount AS DECIMAL(18,6))) * 100
)
WHEN o.plan_amount > 0
THEN (CAST(ISNULL(o.complete_amount,0) AS DECIMAL(18,6)) / CAST(o.plan_amount AS DECIMAL(18,6))) * 100
ELSE 0
END
AS DECIMAL(10,2)), '%'
) AS overallProgress,
-- 进度状态判断:延期或正常
CASE
WHEN o.plan_end_time IS NOT NULL AND GETDATE() > o.plan_end_time AND ISNULL(o.complete_amount,0) &lt; o.plan_amount
THEN '延期'
ELSE '正常'
END AS progressStatus,
ISNULL(ps.totalProcessCount, 0) AS totalProcessCountNum,
CAST(ISNULL(ps.wipWeightedSum, 0) AS DECIMAL(18,2)) AS wipWeightedSum,
-- 数值型整体进度
CAST(
CASE
WHEN o.plan_amount > 0 AND ps.totalProcessCount > 0
THEN (
-- 已完成数量占比
(CAST(ISNULL(o.complete_amount,0) AS DECIMAL(18,6)) / CAST(o.plan_amount AS DECIMAL(18,6))) * 100 +
-- 在制品进度占比
(CAST(ISNULL(o.plan_amount - o.complete_amount,0) AS DECIMAL(18,6)) / CAST(o.plan_amount AS DECIMAL(18,6))) *
(CAST(ISNULL(ps.maxCompletedOrder, 0) + 1 AS DECIMAL(18,6)) / CAST(ps.totalProcessCount AS DECIMAL(18,6))) * 100
)
WHEN o.plan_amount > 0
THEN (CAST(ISNULL(o.complete_amount,0) AS DECIMAL(18,6)) / CAST(o.plan_amount AS DECIMAL(18,6))) * 100
ELSE 0
END
AS DECIMAL(10,2)) AS overallProgressNum
FROM prod_order_info o
INNER JOIN base_material_info m ON m.material_id = o.material_id
INNER JOIN Orders ord ON ord.product_order_id = o.product_order_id AND ord.tenant_id = o.tenant_id
LEFT JOIN ProcessStats ps ON ps.product_order_id = o.product_order_id AND ps.tenant_id = o.tenant_id
<where>
<!-- 进度状态过滤单独保留在最终结果上 -->
<if test="map.progressStatus != null and map.progressStatus != ''">
AND CASE
WHEN o.plan_end_time IS NOT NULL AND GETDATE() > o.plan_end_time AND ISNULL(o.complete_amount,0) &lt; o.plan_amount
@ -356,27 +459,92 @@
END = #{map.progressStatus}
</if>
</where>
ORDER BY o.order_code
ORDER BY o.order_code DESC
</select>
<!-- 获取订单的工序进度详情 -->
<!-- 获取订单的工序进度详情 - 高性能优化版本保留单订单查询不返回productOrderId以兼容旧用法 -->
<select id="getOrderProcessProgress" resultType="org.dromara.mes.domain.vo.ProcessProgressVo">
SELECT
p.process_id AS processId,
pr.process_name AS processName,
p.process_order AS processOrder,
p.plan_status AS planStatus,
CASE p.plan_status
ISNULL(pr.process_name, '未知工序') AS processName,
ISNULL(p.process_order, 0) AS processOrder,
ISNULL(p.plan_status, '0') AS planStatus,
CASE ISNULL(p.plan_status, '0')
WHEN '0' THEN '未派工'
WHEN '1' THEN '已派工'
WHEN '2' THEN '进行中'
WHEN '3' THEN '已完成'
ELSE '未知'
END AS statusDesc,
CASE WHEN p.plan_status = '3' THEN 1 ELSE 0 END AS isCompleted
CASE WHEN p.plan_status = '3' THEN 1 ELSE 0 END AS isCompleted,
CASE WHEN p.plan_status = '2' THEN 1 ELSE 0 END AS isInProgress,
CAST(ISNULL(p.plan_amount, 0) AS DECIMAL(18,2)) AS planAmount,
CAST(ISNULL(p.complete_amount, 0) AS DECIMAL(18,2)) AS completeAmount,
CAST(ISNULL(p.plan_amount, 0) - ISNULL(p.complete_amount, 0) AS DECIMAL(18,2)) AS remainingAmount,
-- 工序进度百分比
CAST(
CASE
WHEN ISNULL(p.plan_amount, 0) > 0
THEN (CAST(ISNULL(p.complete_amount, 0) AS DECIMAL(18,6)) / CAST(p.plan_amount AS DECIMAL(18,6))) * 100
ELSE 0
END
AS DECIMAL(10,2)) AS processProgress,
-- 计划开始时间和结束时间
p.plan_begin_time AS planBeginTime,
p.plan_end_time AS planEndTime,
p.real_begin_time AS realBeginTime,
p.real_end_time AS realEndTime
FROM ${planTableName} p
LEFT JOIN prod_base_process_info pr ON pr.process_id = p.process_id
WHERE p.product_order_id = #{productOrderId}
ORDER BY p.process_order
</select>
<!-- 批量获取订单的工序进度详情避免N+1一次查询一个工序表 -->
<!-- 说明:
1. 通过 IN 子句一次性查询多个订单的工序进度,显著减少数据库往返,提高性能;
2. 返回 product_order_id 字段用于在服务层进行分组映射;
3. 该SQL按订单ID与工序顺序排序便于后续按工序顺序展示
-->
<select id="getOrdersProcessProgressBatch" resultType="org.dromara.mes.domain.vo.ProcessProgressVo">
SELECT
p.product_order_id AS productOrderId,
p.process_id AS processId,
ISNULL(pr.process_name, '未知工序') AS processName,
ISNULL(p.process_order, 0) AS processOrder,
ISNULL(p.plan_status, '0') AS planStatus,
CASE ISNULL(p.plan_status, '0')
WHEN '0' THEN '未派工'
WHEN '1' THEN '已派工'
WHEN '2' THEN '进行中'
WHEN '3' THEN '已完成'
ELSE '未知'
END AS statusDesc,
CASE WHEN p.plan_status = '3' THEN 1 ELSE 0 END AS isCompleted,
CASE WHEN p.plan_status = '2' THEN 1 ELSE 0 END AS isInProgress,
CAST(ISNULL(p.plan_amount, 0) AS DECIMAL(18,2)) AS planAmount,
CAST(ISNULL(p.complete_amount, 0) AS DECIMAL(18,2)) AS completeAmount,
CAST(ISNULL(p.plan_amount, 0) - ISNULL(p.complete_amount, 0) AS DECIMAL(18,2)) AS remainingAmount,
CAST(
CASE
WHEN ISNULL(p.plan_amount, 0) > 0
THEN (CAST(ISNULL(p.complete_amount, 0) AS DECIMAL(18,6)) / CAST(p.plan_amount AS DECIMAL(18,6))) * 100
ELSE 0
END
AS DECIMAL(10,2)) AS processProgress,
p.plan_begin_time AS planBeginTime,
p.plan_end_time AS planEndTime,
p.real_begin_time AS realBeginTime,
p.real_end_time AS realEndTime
FROM ${planTableName} p
LEFT JOIN prod_base_process_info pr ON pr.process_id = p.process_id
WHERE p.product_order_id IN
<foreach collection="productOrderIds" item="id" open="(" separator="," close=")">
#{id}
</foreach>
<if test="tenantId != null"> AND p.tenant_id = #{tenantId} </if>
ORDER BY p.product_order_id, p.process_order
</select>
</mapper>

Loading…
Cancel
Save