feat(mes): 新增工序工单统计与计划子节点查询功能

- 新增工序工单统计接口,支持按工序聚合完成数量、未完成数量与完成率
- 新增计划子节点查询接口,支持按 plan_code + process_id 过滤
-优化在制品跟踪报表SQL逻辑,从订单维度调整为计划编码维度
- 批量工序进度查询由订单ID改为计划编码方式实现- 在报表查询中增加租户隔离控制,确保数据安全性
- 重构相关VO对象,补充物料名称与编码字段以增强展示能力
- 调整WIP跟踪报表排序规则,提升分页浏览体验- 清理历史订单维度的工序进度查询逻辑,统一使用计划维度处理
master
zangch@mesnac.com 2 months ago
parent b93fa3243f
commit b3910bff35

@ -192,4 +192,22 @@ public class ProdReportController extends BaseController {
return R.ok(vos); return R.ok(vos);
} }
/**
*
*/
@GetMapping("/processWorkOrderStats")
public R<List<HashMap<String, Object>>> processWorkOrderStats(@RequestParam(required = false) Map hashMap) {
List<HashMap<String, Object>> vos = prodReportService.processWorkOrderStats(hashMap);
return R.ok(vos);
}
/**
* plan_code + process_id
*/
@GetMapping("/planProcessChildren")
public R<List<HashMap<String, Object>>> planProcessChildren(@RequestParam(required = false) Map hashMap) {
List<HashMap<String, Object>> vos = prodReportService.planProcessDetailChildren(hashMap);
return R.ok(vos);
}
} }

@ -23,6 +23,7 @@ public class ProcessProgressVo implements Serializable {
* ID * ID
*/ */
private Long productOrderId; private Long productOrderId;
private String planCode;
/** /**
* ID * ID
@ -98,4 +99,22 @@ public class ProcessProgressVo implements Serializable {
* *
*/ */
private LocalDateTime realEndTime; private LocalDateTime realEndTime;
/**
*
*/
private String materialName;
/**
*
*/
private String materialCode;
// public String getPlanCode() {
// return planCode;
// }
// public void setPlanCode(String planCode) {
// this.planCode = planCode;
// }
} }

@ -124,17 +124,28 @@ public interface ProdReportMapper {
Long wipTrackingReportCount(@Param("map") Map hashMap); Long wipTrackingReportCount(@Param("map") Map hashMap);
/** /**
* * plan_code + process_id
*/ */
List<ProcessProgressVo> getOrderProcessProgress(@Param("productOrderId") Long productOrderId, @Param("planTableName") String planTableName); List<HashMap<String, Object>> getPlanProcessDetailChildren(@Param("planCode") String planCode,
@Param("processId") Long processId,
@Param("detailTableName") String detailTableName,
@Param("planTableName") String planTableName,
@Param("tenantId") String tenantId);
/** /**
* N+1 * planCode
* @param productOrderIds ID */
List<ProcessProgressVo> getPlanProcessProgress(@Param("planCode") String planCode,
@Param("planTableName") String planTableName);
/**
* planCode
* @param planCodes
* @param planTableName prod_plan_info_2/_3/_4 * @param planTableName prod_plan_info_2/_3/_4
* @param tenantId ID
* @return * @return
*/ */
List<ProcessProgressVo> getOrdersProcessProgressBatch(@Param("productOrderIds") List<Long> productOrderIds, List<ProcessProgressVo> getPlansProcessProgressBatch(@Param("planCodes") List<String> planCodes,
@Param("planTableName") String planTableName, @Param("planTableName") String planTableName,
@Param("tenantId") String tenantId); @Param("tenantId") String tenantId);
@ -142,4 +153,11 @@ public interface ProdReportMapper {
List<HashMap<String, Object>> hourlyOutputByHour(@Param("map") Map hashMap, List<HashMap<String, Object>> hourlyOutputByHour(@Param("map") Map hashMap,
@Param("detailTableName") String detailTableName, @Param("detailTableName") String detailTableName,
@Param("planTableName") String planTableName); @Param("planTableName") String planTableName);
/**
*
*
*/
List<HashMap<String, Object>> processWorkOrderStats(@Param("map") Map hashMap,
@Param("planTableName") String planTableName);
} }

@ -136,4 +136,18 @@ public interface IProdReportService {
*/ */
List<HashMap<String, Object>> hourlyOutputByHour(Map hashMap); List<HashMap<String, Object>> hourlyOutputByHour(Map hashMap);
/**
*
* @param hashMap beginDate/endDateprocessIdmachineIdshiftIdclassTeamIdmaterialName
* @return
*/
List<HashMap<String, Object>> processWorkOrderStats(Map hashMap);
/**
* plan_code + process_id
* @param hashMap planCodeprocessId
* @return
*/
List<HashMap<String, Object>> planProcessDetailChildren(Map hashMap);
} }

@ -172,7 +172,7 @@ public class ProdReportServiceImpl implements IProdReportService {
// 新增辅助方法用于安全解析 processId // 新增辅助方法用于安全解析 processId
private Long parseProcessId(Object processIdObj) { private Long parseProcessId(Object processIdObj) {
if (processIdObj == null) { if (processIdObj == null) {
return null; // 或者根据业务需要返回默认值如 16L return null;
} }
try { try {
@ -208,6 +208,14 @@ public class ProdReportServiceImpl implements IProdReportService {
*/ */
@Override @Override
public TableDataInfo<WipTrackingReportVo> wipTrackingReportList(Map hashMap, PageQuery pageQuery) { public TableDataInfo<WipTrackingReportVo> wipTrackingReportList(Map hashMap, PageQuery pageQuery) {
// 注入租户范围,确保仅查询当前租户数据
try {
String tenantId = LoginHelper.getTenantId();
if (tenantId != null && !tenantId.isEmpty()) {
hashMap.put("tenantId", tenantId);
}
} catch (Exception ignore) {
}
// 使用优化后的SQL查询大部分计算已在数据库层完成 // 使用优化后的SQL查询大部分计算已在数据库层完成
// 关闭自动 count避免对复杂 CTE SQL 的解析失败 // 关闭自动 count避免对复杂 CTE SQL 的解析失败
Page<WipTrackingReportVo> mpPage = pageQuery.build(); Page<WipTrackingReportVo> mpPage = pageQuery.build();
@ -237,6 +245,15 @@ public class ProdReportServiceImpl implements IProdReportService {
*/ */
@Override @Override
public List<WipTrackingReportVo> wipTrackingReportList(Map hashMap) { public List<WipTrackingReportVo> wipTrackingReportList(Map hashMap) {
// 注入租户范围,确保仅查询当前租户数据
try {
String tenantId = LoginHelper.getTenantId();
if (tenantId != null && !tenantId.isEmpty()) {
hashMap.put("tenantId", tenantId);
}
} catch (Exception ignore) {
}
// 使用优化后的SQL查询大部分计算已在数据库层完成 // 使用优化后的SQL查询大部分计算已在数据库层完成
List<WipTrackingReportVo> list = prodReportMapper.wipTrackingReportList(hashMap); List<WipTrackingReportVo> list = prodReportMapper.wipTrackingReportList(hashMap);
@ -255,28 +272,28 @@ public class ProdReportServiceImpl implements IProdReportService {
return; return;
} }
// 批量获取所有订单的工序进度信息 // 批量获取所有计划的工序进度信息按planCode维度
Map<Long, List<ProcessProgressVo>> orderProcessMap = new HashMap<>(); Map<String, List<ProcessProgressVo>> planProcessMap = new HashMap<>();
try { try {
// 收集所有需要查询的订单ID // 收集所有需要查询的计划编码
List<Long> orderIds = reportList.stream() List<String> planCodes = reportList.stream()
.map(WipTrackingReportVo::getProductOrderId) .map(WipTrackingReportVo::getPlanCode)
.filter(Objects::nonNull) .filter(code -> code != null && !code.isEmpty())
.distinct() .distinct()
.collect(Collectors.toList()); .collect(Collectors.toList());
if (orderIds.isEmpty()) { if (planCodes.isEmpty()) {
return; return;
} }
// 批量查询各个工序表的进度信息 // 批量查询各个工序表的进度信息(按计划编码)
batchQueryProcessProgress(orderIds, orderProcessMap); batchQueryProcessProgress(planCodes, planProcessMap);
// 为每个报表项设置工序进度信息 // 为每个报表项设置工序进度信息
for (WipTrackingReportVo vo : reportList) { for (WipTrackingReportVo vo : reportList) {
if (vo.getProductOrderId() != null) { if (vo.getPlanCode() != null && !vo.getPlanCode().isEmpty()) {
List<ProcessProgressVo> processProgress = orderProcessMap.get(vo.getProductOrderId()); List<ProcessProgressVo> processProgress = planProcessMap.get(vo.getPlanCode());
if (processProgress != null && !processProgress.isEmpty()) { if (processProgress != null && !processProgress.isEmpty()) {
vo.setProcessProgressList(processProgress); vo.setProcessProgressList(processProgress);
// 基于实际工序进度微调计算结果 // 基于实际工序进度微调计算结果
@ -288,7 +305,7 @@ public class ProdReportServiceImpl implements IProdReportService {
} }
} catch (Exception e) { } catch (Exception e) {
System.out.println("批量获取工序进度信息失败: " + e.getMessage()); System.out.println("批量获取工序进度信息失败(按planCode): " + e.getMessage());
// 降级处理:为每个订单单独查询 // 降级处理:为每个订单单独查询
fallbackToIndividualQuery(reportList); fallbackToIndividualQuery(reportList);
} }
@ -299,18 +316,18 @@ public class ProdReportServiceImpl implements IProdReportService {
* @param orderIds ID * @param orderIds ID
* @param orderProcessMap * @param orderProcessMap
*/ */
private void batchQueryProcessProgress(List<Long> orderIds, Map<Long, List<ProcessProgressVo>> orderProcessMap) { private void batchQueryProcessProgress(List<String> planCodes, Map<String, List<ProcessProgressVo>> planProcessMap) {
// 查询半制品工序进度prod_plan_info_2 // 查询半制品工序进度prod_plan_info_2
queryProcessProgressByTable(orderIds, "prod_plan_info_2", orderProcessMap); queryProcessProgressByTable(planCodes, "prod_plan_info_2", planProcessMap);
// 查询成型工序进度prod_plan_info_3 // 查询成型工序进度prod_plan_info_3
queryProcessProgressByTable(orderIds, "prod_plan_info_3", orderProcessMap); queryProcessProgressByTable(planCodes, "prod_plan_info_3", planProcessMap);
// 查询硫化工序进度prod_plan_info_4 // 查询硫化工序进度prod_plan_info_4
queryProcessProgressByTable(orderIds, "prod_plan_info_4", orderProcessMap); queryProcessProgressByTable(planCodes, "prod_plan_info_4", planProcessMap);
// 对每个订单的工序进度进行排序 // 对每个计划的工序进度进行排序
orderProcessMap.values().forEach(processList -> planProcessMap.values().forEach(processList ->
processList.sort((a, b) -> { processList.sort((a, b) -> {
if (a.getProcessOrder() == null) return 1; if (a.getProcessOrder() == null) return 1;
if (b.getProcessOrder() == null) return -1; if (b.getProcessOrder() == null) return -1;
@ -325,23 +342,23 @@ public class ProdReportServiceImpl implements IProdReportService {
* @param tableName * @param tableName
* @param orderProcessMap * @param orderProcessMap
*/ */
private void queryProcessProgressByTable(List<Long> orderIds, String tableName, Map<Long, List<ProcessProgressVo>> orderProcessMap) { private void queryProcessProgressByTable(List<String> planCodes, String tableName, Map<String, List<ProcessProgressVo>> planProcessMap) {
try { try {
// 使用批量查询避免 N+1一次性查询该工序表下所有订单的工序进度 // 使用批量查询避免 N+1一次性查询该工序表下所有计划的工序进度
// 返回结果中包含 productOrderId 字段,便于在此处进行分组 // 返回结果中包含 planCode 字段,便于在此处进行分组
String tenantId = LoginHelper.getTenantId(); String tenantId = LoginHelper.getTenantId();
List<ProcessProgressVo> batchResults = prodReportMapper.getOrdersProcessProgressBatch(orderIds, tableName, tenantId); List<ProcessProgressVo> batchResults = prodReportMapper.getPlansProcessProgressBatch(planCodes, tableName, tenantId);
if (batchResults != null && !batchResults.isEmpty()) { if (batchResults != null && !batchResults.isEmpty()) {
for (ProcessProgressVo progress : batchResults) { for (ProcessProgressVo progress : batchResults) {
Long orderId = progress.getProductOrderId(); String planCode = progress.getPlanCode();
if (orderId != null) { if (planCode != null && !planCode.isEmpty()) {
orderProcessMap.computeIfAbsent(orderId, k -> new ArrayList<>()).add(progress); planProcessMap.computeIfAbsent(planCode, k -> new ArrayList<>()).add(progress);
} }
} }
} }
} catch (Exception e) { } catch (Exception e) {
// 记录失败但不中断整体处理,后续会有降级策略 // 记录失败但不中断整体处理,后续会有降级策略
System.out.println("批量查询表 " + tableName + " 的工序进度失败: " + e.getMessage()); System.out.println("批量查询表 " + tableName + " 的工序进度失败(按planCode): " + e.getMessage());
} }
} }
@ -388,7 +405,7 @@ public class ProdReportServiceImpl implements IProdReportService {
vo.setRemainingProcesses(remainingProcesses); vo.setRemainingProcesses(remainingProcesses);
} catch (Exception e) { } catch (Exception e) {
System.out.println("微调进度计算失败,订单ID: " + vo.getProductOrderId() + ", 错误: " + e.getMessage()); System.out.println("微调进度计算失败,计划编码: " + vo.getPlanCode() + ", 错误: " + e.getMessage());
} }
} }
@ -398,13 +415,13 @@ public class ProdReportServiceImpl implements IProdReportService {
*/ */
private void fallbackToIndividualQuery(List<WipTrackingReportVo> reportList) { private void fallbackToIndividualQuery(List<WipTrackingReportVo> reportList) {
for (WipTrackingReportVo vo : reportList) { for (WipTrackingReportVo vo : reportList) {
if (vo.getProductOrderId() != null) { if (vo.getPlanCode() != null && !vo.getPlanCode().isEmpty()) {
try { try {
List<ProcessProgressVo> processProgress = getAllOrderProcessProgressOptimized(vo.getProductOrderId()); List<ProcessProgressVo> processProgress = getAllPlanProcessProgressOptimized(vo.getPlanCode());
vo.setProcessProgressList(processProgress); vo.setProcessProgressList(processProgress);
adjustProgressCalculation(vo, processProgress); adjustProgressCalculation(vo, processProgress);
} catch (Exception e) { } catch (Exception e) {
System.out.println("单独查询订单工序进度失败订单ID: " + vo.getProductOrderId()); System.out.println("单独查询计划工序进度失败,计划编码: " + vo.getPlanCode());
vo.setProcessProgressList(new ArrayList<>()); vo.setProcessProgressList(new ArrayList<>());
} }
} }
@ -412,40 +429,47 @@ public class ProdReportServiceImpl implements IProdReportService {
} }
/** /**
* * plan_code + process_id
* @param productOrderId ID */
@Override
public List<HashMap<String, Object>> planProcessDetailChildren(Map hashMap) {
Long processId = parseProcessId(hashMap.get("processId"));
String detailTable = getPlanDetailTableNameByProcessId(processId);
String planTable = getPlanInfoTableNameByProcessId(processId);
String planCode = String.valueOf(hashMap.get("planCode"));
String tenantId = LoginHelper.getTenantId();
return prodReportMapper.getPlanProcessDetailChildren(planCode, processId, detailTable, planTable, tenantId);
}
/**
* planCode
* @param planCode
* @return * @return
*/ */
private List<ProcessProgressVo> getAllOrderProcessProgressOptimized(Long productOrderId) { private List<ProcessProgressVo> getAllPlanProcessProgressOptimized(String planCode) {
List<ProcessProgressVo> allProcessProgress = new java.util.ArrayList<>(); List<ProcessProgressVo> allProcessProgress = new java.util.ArrayList<>();
try { try {
// 1. 获取订单信息 // 不依赖 prod_order_info直接查询三个计划表
var orderInfo = prodOrderInfoMapper.selectById(productOrderId); String[] planTables = {
if (orderInfo == null) { DatabaseConstants.TABLE_NAME_PROD_PLAN_INFO_PREFIX + "_2",
return allProcessProgress; DatabaseConstants.TABLE_NAME_PROD_PLAN_INFO_PREFIX + "_3",
} DatabaseConstants.TABLE_NAME_PROD_PLAN_INFO_PREFIX + "_4"
};
// 2. 根据派工类型确定需要查询的工序表 for (String planTableName : planTables) {
List<Long> processIds = determineProcessIds(orderInfo);
// 3. 并行查询各工序表以提高性能
for (Long processId : processIds) {
try { try {
String planTableName = getPlanInfoTableNameByProcessId(processId); List<ProcessProgressVo> processProgress = prodReportMapper.getPlanProcessProgress(planCode, planTableName);
if (planTableName != null) {
List<ProcessProgressVo> processProgress = prodReportMapper.getOrderProcessProgress(productOrderId, planTableName);
if (processProgress != null && !processProgress.isEmpty()) { if (processProgress != null && !processProgress.isEmpty()) {
allProcessProgress.addAll(processProgress); allProcessProgress.addAll(processProgress);
} }
}
} catch (Exception e) { } catch (Exception e) {
// 记录日志但不中断处理 // 记录日志但不中断处理
System.out.println("查询工序进度失败,订单ID: " + productOrderId + ", 工序ID: " + processId + ", 错误: " + e.getMessage()); System.out.println("查询工序进度失败,计划编码: " + planCode + ", 表: " + planTableName + ", 错误: " + e.getMessage());
} }
} }
// 4. 按工序顺序排序 // 按工序顺序排序
allProcessProgress.sort((a, b) -> { allProcessProgress.sort((a, b) -> {
if (a.getProcessOrder() == null) return 1; if (a.getProcessOrder() == null) return 1;
if (b.getProcessOrder() == null) return -1; if (b.getProcessOrder() == null) return -1;
@ -453,7 +477,7 @@ public class ProdReportServiceImpl implements IProdReportService {
}); });
} catch (Exception e) { } catch (Exception e) {
System.out.println("获取订单工序进度失败订单ID: " + productOrderId + ", 错误: " + e.getMessage()); System.out.println("获取计划工序进度失败,计划编码: " + planCode + ", 错误: " + e.getMessage());
} }
return allProcessProgress; return allProcessProgress;
@ -595,4 +619,15 @@ public class ProdReportServiceImpl implements IProdReportService {
} }
/**
*
* processId
*/
@Override
public List<HashMap<String, Object>> processWorkOrderStats(Map hashMap) {
Long processId = parseProcessId(hashMap.get("processId"));
String planTable = getPlanInfoTableNameByProcessId(processId);
return prodReportMapper.processWorkOrderStats(hashMap, planTable);
}
} }

@ -1,4 +1,4 @@
<?xml version="1.0" encoding="UTF-8" ?> <?xml version="1.0" encoding="UTF-8" ?>
<!DOCTYPE mapper <!DOCTYPE mapper
PUBLIC "-//mybatis.org//DTD Mapper 3.0//EN" PUBLIC "-//mybatis.org//DTD Mapper 3.0//EN"
"http://mybatis.org/dtd/mybatis-3-mapper.dtd"> "http://mybatis.org/dtd/mybatis-3-mapper.dtd">
@ -295,21 +295,28 @@
ORDER BY ppd.real_begin_time DESC, ppi.plan_id DESC ORDER BY ppd.real_begin_time DESC, ppi.plan_id DESC
</select> </select>
<!-- 在制品跟踪报表 - 高性能优化版本(进一步优化:限制工序统计范围到已过滤订单,避免全表扫描;使用索引友好时间过滤 --> <!-- 在制品跟踪报表 - 高性能优化版本(进一步优化:限制工序统计范围到已过滤订单,避免全表扫描 -->
<select id="wipTrackingReportList" resultType="org.dromara.mes.domain.vo.WipTrackingReportVo"> <select id="wipTrackingReportList" resultType="org.dromara.mes.domain.vo.WipTrackingReportVo">
WITH Orders AS ( WITH Plans AS (
-- 先根据筛选条件提取订单范围,避免后续工序统计对全库扫描(索引友好) SELECT p.plan_code, p.tenant_id
SELECT o.product_order_id, o.tenant_id FROM (
FROM prod_order_info o SELECT product_order_id, tenant_id, material_id, plan_begin_time, plan_code FROM prod_plan_info_2
INNER JOIN base_material_info m ON m.material_id = o.material_id UNION ALL
SELECT product_order_id, tenant_id, material_id, plan_begin_time, plan_code FROM prod_plan_info_3
UNION ALL
SELECT product_order_id, tenant_id, material_id, plan_begin_time, plan_code FROM prod_plan_info_4
) p
INNER JOIN base_material_info m ON m.material_id = p.material_id
WHERE m.del_flag = '0' WHERE m.del_flag = '0'
<if test="map.beginDate != null and map.beginDate != '' and map.endDate != null and map.endDate != ''"> <if test="map.tenantId != null and map.tenantId != ''">
-- 时间范围过滤:避免对列使用函数,保持索引可用 AND p.tenant_id = #{map.tenantId}
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>
<if test="map.orderCode != null and map.orderCode != ''"> <if test="map.beginDate != null and map.beginDate != '' and map.endDate != null and map.endDate != ''">
AND o.order_code LIKE CONCAT('%', #{map.orderCode}, '%') AND p.plan_begin_time &gt;= CAST(#{map.beginDate} AS DATETIME)
AND p.plan_begin_time &lt; DATEADD(day, 1, CAST(#{map.endDate} AS DATETIME))
</if>
<if test="map.planCode != null and map.planCode != ''">
AND p.plan_code LIKE CONCAT('%', #{map.planCode}, '%')
</if> </if>
<if test="map.materialName != null and map.materialName != ''"> <if test="map.materialName != null and map.materialName != ''">
AND m.material_name LIKE CONCAT('%', #{map.materialName}, '%') AND m.material_name LIKE CONCAT('%', #{map.materialName}, '%')
@ -317,86 +324,99 @@
<if test="map.materialCode != null and map.materialCode != ''"> <if test="map.materialCode != null and map.materialCode != ''">
AND m.material_code LIKE CONCAT('%', #{map.materialCode}, '%') AND m.material_code LIKE CONCAT('%', #{map.materialCode}, '%')
</if> </if>
GROUP BY p.plan_code, p.tenant_id
), ),
ProcessStats AS ( ProcessRows AS (
-- 统计每个订单的工序进度信息仅统计已过滤的订单范围UNION ALL 提升性能) -- 订单范围内的所有工序计划行UNION ALL 提升性能)
SELECT SELECT p2.plan_code, p2.tenant_id, p2.process_id, p2.process_order, p2.plan_status,
ap.product_order_id, p2.plan_amount, p2.complete_amount, pr2.process_name
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 FROM prod_plan_info_2 p2
LEFT JOIN prod_base_process_info pr2 ON pr2.process_id = p2.process_id 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 INNER JOIN Plans pl ON pl.plan_code = p2.plan_code AND pl.tenant_id = p2.tenant_id
WHERE p2.product_order_id IS NOT NULL
UNION ALL UNION ALL
-- 成型工序prod_plan_info_3 SELECT p3.plan_code, p3.tenant_id, p3.process_id, p3.process_order, p3.plan_status,
SELECT p3.plan_amount, p3.complete_amount, pr3.process_name
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 FROM prod_plan_info_3 p3
LEFT JOIN prod_base_process_info pr3 ON pr3.process_id = p3.process_id 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 INNER JOIN Plans pl ON pl.plan_code = p3.plan_code AND pl.tenant_id = p3.tenant_id
WHERE p3.product_order_id IS NOT NULL
UNION ALL UNION ALL
-- 硫化工序prod_plan_info_4 SELECT p4.plan_code, p4.tenant_id, p4.process_id, p4.process_order, p4.plan_status,
SELECT p4.plan_amount, p4.complete_amount, pr4.process_name
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 FROM prod_plan_info_4 p4
LEFT JOIN prod_base_process_info pr4 ON pr4.process_id = p4.process_id 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 INNER JOIN Plans pl ON pl.plan_code = p4.plan_code AND pl.tenant_id = p4.tenant_id
WHERE p4.product_order_id IS NOT NULL ),
) AS ap DistinctProcess AS (
GROUP BY ap.product_order_id, ap.tenant_id -- 按计划+工序聚合为唯一工序,避免同一工序多行导致工序数偏大
SELECT
plan_code,
tenant_id,
process_id,
MAX(ISNULL(process_order,0)) AS process_order,
MAX(CASE WHEN plan_status = '3' THEN 1 ELSE 0 END) AS isCompleted,
MAX(CASE WHEN plan_status = '2' THEN 1 ELSE 0 END) AS isInProgress,
SUM(ISNULL(plan_amount,0)) AS plan_amount,
SUM(ISNULL(complete_amount,0)) AS complete_amount,
MAX(process_name) AS process_name
FROM ProcessRows
GROUP BY plan_code, tenant_id, process_id
),
ProcessStats AS (
-- 统计每个订单的工序进度(以唯一工序为单位)
SELECT
dp.plan_code,
dp.tenant_id,
COUNT(*) AS totalProcessCount,
SUM(dp.isCompleted) AS completedProcessCount,
SUM(dp.isInProgress) AS wipProcessCount,
MAX(CASE WHEN dp.isCompleted = 1 THEN dp.process_order ELSE 0 END) AS maxCompletedOrder,
STRING_AGG(CASE WHEN dp.isInProgress = 1 THEN dp.process_name END, ',') AS wipProcessNames,
STRING_AGG(CASE WHEN dp.isCompleted = 0 AND dp.isInProgress = 0 THEN dp.process_name END, ',') AS remainingProcessNames,
SUM(CASE WHEN dp.isInProgress = 1 THEN ISNULL(dp.plan_amount - dp.complete_amount, 0) * dp.process_order ELSE 0 END) AS wipWeightedSum
FROM DistinctProcess dp
GROUP BY dp.plan_code, dp.tenant_id
),
PlanAgg AS (
-- 按计划聚合计划信息(按 plan_code 维度)
SELECT
p.plan_code,
p.tenant_id,
MIN(p.plan_begin_time) AS plan_begin_time,
MIN(p.real_begin_time) AS real_begin_time,
MAX(p.plan_end_time) AS plan_end_time,
SUM(ISNULL(p.plan_amount,0)) AS plan_amount,
SUM(ISNULL(p.complete_amount,0)) AS complete_amount,
MAX(p.material_id) AS material_id
FROM (
SELECT plan_code, tenant_id, plan_begin_time, real_begin_time, plan_end_time, plan_amount, complete_amount, material_id
FROM prod_plan_info_2
UNION ALL
SELECT plan_code, tenant_id, plan_begin_time, real_begin_time, plan_end_time, plan_amount, complete_amount, material_id
FROM prod_plan_info_3
UNION ALL
SELECT plan_code, tenant_id, plan_begin_time, real_begin_time, plan_end_time, plan_amount, complete_amount, material_id
FROM prod_plan_info_4
) p
INNER JOIN Plans pl ON pl.plan_code = p.plan_code AND pl.tenant_id = p.tenant_id
GROUP BY p.plan_code, p.tenant_id
) )
SELECT SELECT
o.product_order_id AS productOrderId, NULL AS productOrderId,
o.order_code AS orderCode, '' AS orderCode,
oa.plan_code AS planCode,
m.material_code AS materialCode, m.material_code AS materialCode,
m.material_name AS materialName, m.material_name AS materialName,
ISNULL(m.material_spec, '') AS materialSpec, ISNULL(m.material_spec, '') AS materialSpec,
CAST(o.plan_amount AS DECIMAL(18,2)) AS planAmount, CAST(oa.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(oa.plan_amount,0) - ISNULL(oa.complete_amount,0) AS DECIMAL(18,2)) AS wipAmount,
CAST(ISNULL(o.complete_amount,0) AS DECIMAL(18,2)) AS completeAmount, CAST(ISNULL(oa.complete_amount,0) AS DECIMAL(18,2)) AS completeAmount,
o.plan_begin_time AS planBeginTime, oa.plan_begin_time AS planBeginTime,
o.real_begin_time AS realBeginTime, oa.real_begin_time AS realBeginTime,
o.plan_end_time AS planEndTime, oa.plan_end_time AS planEndTime,
GETDATE() AS currentTime, GETDATE() AS currentTime,
CAST(ISNULL(ps.totalProcessCount, 0) AS VARCHAR(10)) + '道' AS totalProcessCount, CAST(ISNULL(ps.totalProcessCount, 0) AS VARCHAR(10)) + '道' AS totalProcessCount,
@ -406,15 +426,15 @@
CONCAT( CONCAT(
CAST( CAST(
CASE CASE
WHEN o.plan_amount > 0 WHEN oa.plan_amount > 0
THEN (CAST(ISNULL(o.complete_amount,0) AS DECIMAL(18,6)) / CAST(o.plan_amount AS DECIMAL(18,6))) * 100 THEN (CAST(ISNULL(oa.complete_amount,0) AS DECIMAL(18,6)) / CAST(oa.plan_amount AS DECIMAL(18,6))) * 100
ELSE 0 ELSE 0
END END
AS DECIMAL(10,2)), '%' AS DECIMAL(10,2)), '%'
) AS overallProgress, ) AS overallProgress,
-- 进度状态判断:延期或正常 -- 进度状态判断:延期或正常
CASE 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 WHEN oa.plan_end_time IS NOT NULL AND GETDATE() > oa.plan_end_time AND ISNULL(oa.complete_amount,0) &lt; oa.plan_amount
THEN '延期' THEN '延期'
ELSE '正常' ELSE '正常'
END AS progressStatus, END AS progressStatus,
@ -423,40 +443,51 @@
-- 数值型整体进度(不带百分号) -- 数值型整体进度(不带百分号)
CAST( CAST(
CASE CASE
WHEN o.plan_amount > 0 WHEN oa.plan_amount > 0
THEN (CAST(ISNULL(o.complete_amount,0) AS DECIMAL(18,6)) / CAST(o.plan_amount AS DECIMAL(18,6))) * 100 THEN (CAST(ISNULL(oa.complete_amount,0) AS DECIMAL(18,6)) / CAST(oa.plan_amount AS DECIMAL(18,6))) * 100
ELSE 0 ELSE 0
END END
AS DECIMAL(10,2)) AS overallProgressNum AS DECIMAL(10,2)) AS overallProgressNum
FROM prod_order_info o FROM PlanAgg oa
INNER JOIN base_material_info m ON m.material_id = o.material_id INNER JOIN base_material_info m ON m.material_id = oa.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.plan_code = oa.plan_code AND ps.tenant_id = oa.tenant_id
LEFT JOIN ProcessStats ps ON ps.product_order_id = o.product_order_id AND ps.tenant_id = o.tenant_id
<where> <where>
<!-- 进度状态过滤单独保留在最终结果上 --> <!-- 进度状态过滤单独保留在最终结果上 -->
<if test="map.progressStatus != null and map.progressStatus != ''"> <if test="map.progressStatus != null and map.progressStatus != ''">
AND CASE 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 WHEN oa.plan_end_time IS NOT NULL AND GETDATE() > oa.plan_end_time AND ISNULL(oa.complete_amount,0) &lt; oa.plan_amount
THEN '延期' THEN '延期'
ELSE '正常' ELSE '正常'
END = #{map.progressStatus} END = #{map.progressStatus}
</if> </if>
</where> </where>
ORDER BY o.order_code DESC -- 为避免首屏仅出现以 'PLAN' 开头的计划编号(字符串排序导致),
-- 改为按时间优先降序,其次按计划编号升序,确保不同编码规则的计划均能出现在第一页
ORDER BY oa.plan_begin_time DESC, oa.real_begin_time DESC, oa.plan_code ASC
</select> </select>
<!-- 在制品跟踪报表总数(简化版 count避免复杂 CTE/聚合,保持与筛选条件一致 --> <!-- 在制品跟踪报表总数(按工序维度计数):统计筛选范围内存在数据的工序数量 -->
<select id="wipTrackingReportCount" resultType="java.lang.Long"> <select id="wipTrackingReportCount" resultType="java.lang.Long">
SELECT COUNT(*) WITH Plans AS (
FROM prod_order_info o SELECT p.plan_code, p.tenant_id
INNER JOIN base_material_info m ON m.material_id = o.material_id FROM (
SELECT product_order_id, tenant_id, material_id, plan_begin_time, plan_code FROM prod_plan_info_2
UNION ALL
SELECT product_order_id, tenant_id, material_id, plan_begin_time, plan_code FROM prod_plan_info_3
UNION ALL
SELECT product_order_id, tenant_id, material_id, plan_begin_time, plan_code FROM prod_plan_info_4
) p
INNER JOIN base_material_info m ON m.material_id = p.material_id
WHERE m.del_flag = '0' WHERE m.del_flag = '0'
<if test="map.beginDate != null and map.beginDate != '' and map.endDate != null and map.endDate != ''"> <if test="map.tenantId != null and map.tenantId != ''">
AND o.plan_begin_time <![CDATA[>=]]> CAST(#{map.beginDate} AS DATETIME) AND p.tenant_id = #{map.tenantId}
AND o.plan_begin_time <![CDATA[<]]> DATEADD(day, 1, CAST(#{map.endDate} AS DATETIME))
</if> </if>
<if test="map.orderCode != null and map.orderCode != ''"> <if test="map.beginDate != null and map.beginDate != '' and map.endDate != null and map.endDate != ''">
AND o.order_code LIKE CONCAT('%', #{map.orderCode}, '%') AND p.plan_begin_time <![CDATA[>=]]> CAST(#{map.beginDate} AS DATETIME)
AND p.plan_begin_time <![CDATA[<]]> DATEADD(day, 1, CAST(#{map.endDate} AS DATETIME))
</if>
<if test="map.planCode != null and map.planCode != ''">
AND p.plan_code LIKE CONCAT('%', #{map.planCode}, '%')
</if> </if>
<if test="map.materialName != null and map.materialName != ''"> <if test="map.materialName != null and map.materialName != ''">
AND m.material_name LIKE CONCAT('%', #{map.materialName}, '%') AND m.material_name LIKE CONCAT('%', #{map.materialName}, '%')
@ -464,17 +495,71 @@
<if test="map.materialCode != null and map.materialCode != ''"> <if test="map.materialCode != null and map.materialCode != ''">
AND m.material_code LIKE CONCAT('%', #{map.materialCode}, '%') AND m.material_code LIKE CONCAT('%', #{map.materialCode}, '%')
</if> </if>
GROUP BY p.plan_code, p.tenant_id
),
PlanAgg AS (
-- 计划级聚合(用于进度状态筛选)
SELECT
p.plan_code,
p.tenant_id,
MAX(p.material_id) AS material_id,
MAX(p.plan_end_time) AS plan_end_time,
SUM(ISNULL(p.plan_amount,0)) AS plan_amount,
SUM(ISNULL(p.complete_amount,0)) AS complete_amount
FROM (
SELECT plan_code, tenant_id, plan_end_time, plan_amount, complete_amount, material_id FROM prod_plan_info_2
UNION ALL
SELECT plan_code, tenant_id, plan_end_time, plan_amount, complete_amount, material_id FROM prod_plan_info_3
UNION ALL
SELECT plan_code, tenant_id, plan_end_time, plan_amount, complete_amount, material_id FROM prod_plan_info_4
) p
INNER JOIN Plans pl ON pl.plan_code = p.plan_code AND pl.tenant_id = p.tenant_id
GROUP BY p.plan_code, p.tenant_id
),
EligiblePlans AS (
-- 应用进度状态筛选(如有),得到符合条件的计划集合
SELECT oa.plan_code, oa.tenant_id
FROM PlanAgg oa
INNER JOIN base_material_info m ON m.material_id = oa.material_id
WHERE m.del_flag = '0'
<if test="map.progressStatus != null and map.progressStatus != ''"> <if test="map.progressStatus != null and map.progressStatus != ''">
AND CASE AND CASE
WHEN o.plan_end_time IS NOT NULL AND GETDATE() > o.plan_end_time AND ISNULL(o.complete_amount,0) <![CDATA[<]]> o.plan_amount THEN '延期' WHEN oa.plan_end_time IS NOT NULL AND GETDATE() > oa.plan_end_time AND ISNULL(oa.complete_amount,0) <![CDATA[<]]> oa.plan_amount THEN '延期'
ELSE '正常' ELSE '正常'
END = #{map.progressStatus} END = #{map.progressStatus}
</if> </if>
),
ProcessRows AS (
-- 订单范围内且符合状态筛选的所有工序行
SELECT p2.plan_code, p2.tenant_id, p2.process_id, ISNULL(pr2.process_name, N'未知工序') AS process_name
FROM prod_plan_info_2 p2
LEFT JOIN prod_base_process_info pr2 ON pr2.process_id = p2.process_id
INNER JOIN EligiblePlans ep ON ep.plan_code = p2.plan_code AND ep.tenant_id = p2.tenant_id
UNION ALL
SELECT p3.plan_code, p3.tenant_id, p3.process_id, ISNULL(pr3.process_name, N'未知工序') AS process_name
FROM prod_plan_info_3 p3
LEFT JOIN prod_base_process_info pr3 ON pr3.process_id = p3.process_id
INNER JOIN EligiblePlans ep ON ep.plan_code = p3.plan_code AND ep.tenant_id = p3.tenant_id
UNION ALL
SELECT p4.plan_code, p4.tenant_id, p4.process_id, ISNULL(pr4.process_name, N'未知工序') AS process_name
FROM prod_plan_info_4 p4
LEFT JOIN prod_base_process_info pr4 ON pr4.process_id = p4.process_id
INNER JOIN EligiblePlans ep ON ep.plan_code = p4.plan_code AND ep.tenant_id = p4.tenant_id
)
SELECT COUNT(DISTINCT process_name)
FROM ProcessRows
</select> </select>
<!-- 获取订单的工序进度详情 - 高性能优化版本保留单订单查询不返回productOrderId以兼容旧用法 --> <!-- (已清理)订单维度的工序进度查询已移除,统一按 plan_code 维度处理 -->
<select id="getOrderProcessProgress" resultType="org.dromara.mes.domain.vo.ProcessProgressVo">
<!-- 获取计划的工序进度详情按planCode单条 -->
<select id="getPlanProcessProgress" resultType="org.dromara.mes.domain.vo.ProcessProgressVo">
SELECT SELECT
p.plan_code AS planCode,
p.process_id AS processId, p.process_id AS processId,
ISNULL(pr.process_name, '未知工序') AS processName, ISNULL(pr.process_name, '未知工序') AS processName,
ISNULL(p.process_order, 0) AS processOrder, ISNULL(p.process_order, 0) AS processOrder,
@ -491,34 +576,29 @@
CAST(ISNULL(p.plan_amount, 0) AS DECIMAL(18,2)) AS planAmount, 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.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(ISNULL(p.plan_amount, 0) - ISNULL(p.complete_amount, 0) AS DECIMAL(18,2)) AS remainingAmount,
-- 工序进度百分比
CAST( CAST(
CASE CASE WHEN ISNULL(p.plan_amount, 0) > 0
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 THEN (CAST(ISNULL(p.complete_amount, 0) AS DECIMAL(18,6)) / CAST(p.plan_amount AS DECIMAL(18,6))) * 100
ELSE 0 ELSE 0
END END
AS DECIMAL(10,2)) AS processProgress, AS DECIMAL(10,2)) AS processProgress,
-- 计划开始时间和结束时间
p.plan_begin_time AS planBeginTime, p.plan_begin_time AS planBeginTime,
p.plan_end_time AS planEndTime, p.plan_end_time AS planEndTime,
p.real_begin_time AS realBeginTime, p.real_begin_time AS realBeginTime,
p.real_end_time AS realEndTime p.real_end_time AS realEndTime,
bmi.material_name AS materialName,
bmi.material_code AS materialCode
FROM ${planTableName} p FROM ${planTableName} p
LEFT JOIN prod_base_process_info pr ON pr.process_id = p.process_id LEFT JOIN prod_base_process_info pr ON pr.process_id = p.process_id
WHERE p.product_order_id = #{productOrderId} LEFT JOIN base_material_info bmi ON bmi.material_id = p.material_id
WHERE p.plan_code = #{planCode}
ORDER BY p.process_order ORDER BY p.process_order
</select> </select>
<!-- 批量获取订单的工序进度详情避免N+1一次查询一个工序表 --> <!-- 批量获取计划的工序进度详情按planCode批量 -->
<!-- 说明: <select id="getPlansProcessProgressBatch" resultType="org.dromara.mes.domain.vo.ProcessProgressVo">
1. 通过 IN 子句一次性查询多个订单的工序进度,显著减少数据库往返,提高性能;
2. 返回 product_order_id 字段用于在服务层进行分组映射;
3. 该SQL按订单ID与工序顺序排序便于后续按工序顺序展示
-->
<select id="getOrdersProcessProgressBatch" resultType="org.dromara.mes.domain.vo.ProcessProgressVo">
SELECT SELECT
p.product_order_id AS productOrderId, p.plan_code AS planCode,
p.process_id AS processId, p.process_id AS processId,
ISNULL(pr.process_name, '未知工序') AS processName, ISNULL(pr.process_name, '未知工序') AS processName,
ISNULL(p.process_order, 0) AS processOrder, ISNULL(p.process_order, 0) AS processOrder,
@ -536,8 +616,7 @@
CAST(ISNULL(p.complete_amount, 0) AS DECIMAL(18,2)) AS completeAmount, 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(ISNULL(p.plan_amount, 0) - ISNULL(p.complete_amount, 0) AS DECIMAL(18,2)) AS remainingAmount,
CAST( CAST(
CASE CASE WHEN ISNULL(p.plan_amount, 0) > 0
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 THEN (CAST(ISNULL(p.complete_amount, 0) AS DECIMAL(18,6)) / CAST(p.plan_amount AS DECIMAL(18,6))) * 100
ELSE 0 ELSE 0
END END
@ -545,15 +624,41 @@
p.plan_begin_time AS planBeginTime, p.plan_begin_time AS planBeginTime,
p.plan_end_time AS planEndTime, p.plan_end_time AS planEndTime,
p.real_begin_time AS realBeginTime, p.real_begin_time AS realBeginTime,
p.real_end_time AS realEndTime p.real_end_time AS realEndTime,
bmi.material_name AS materialName,
bmi.material_code AS materialCode
FROM ${planTableName} p FROM ${planTableName} p
LEFT JOIN prod_base_process_info pr ON pr.process_id = p.process_id LEFT JOIN prod_base_process_info pr ON pr.process_id = p.process_id
WHERE p.product_order_id IN LEFT JOIN base_material_info bmi ON bmi.material_id = p.material_id
<foreach collection="productOrderIds" item="id" open="(" separator="," close=")"> WHERE p.plan_code IN
#{id} <foreach collection="planCodes" item="code" open="(" separator="," close=")">
#{code}
</foreach> </foreach>
<if test="tenantId != null"> AND p.tenant_id = #{tenantId} </if> <if test="tenantId != null"> AND p.tenant_id = #{tenantId} </if>
ORDER BY p.product_order_id, p.process_order ORDER BY p.plan_code, p.process_order
</select>
<!-- 工序下的计划子节点查询:按 plan_code + process_id 过滤,计划级视图(不关联明细表) -->
<select id="getPlanProcessDetailChildren" resultType="java.util.HashMap">
SELECT
ppi.plan_id AS planId,
ppi.plan_code AS planCode,
ppi.process_id AS processId,
ppi.process_order AS processOrder,
ISNULL(ppi.plan_amount, 0) AS planAmount,
ISNULL(ppi.complete_amount, 0) AS completeAmount,
ppi.real_begin_time AS realBeginTime,
ppi.real_end_time AS realEndTime,
ISNULL(bct.team_name, '') AS teamName,
ISNULL(pbsi.station_name, '') AS stationName,
ISNULL(ppi.plan_status, '0') AS planStatus
FROM ${planTableName} ppi
LEFT JOIN base_class_team_info bct ON bct.class_team_id = ppi.class_team_id
LEFT JOIN prod_base_station_info pbsi ON pbsi.station_id = bct.station_id
WHERE ppi.plan_code = #{planCode}
<if test="processId != null"> AND ppi.process_id = #{processId} </if>
<if test="tenantId != null"> AND ppi.tenant_id = #{tenantId} </if>
ORDER BY ppi.real_begin_time, ppi.plan_id
</select> </select>
@ -597,4 +702,59 @@
ORDER BY productionDate, DATEPART(HOUR, t.create_time) ORDER BY productionDate, DATEPART(HOUR, t.create_time)
</select> </select>
<!-- 工序生产统计(按工序聚合):完成数量、未完成数量与完成率 -->
<select id="processWorkOrderStats" resultType="java.util.HashMap">
<![CDATA[
SELECT
ISNULL(pproc.process_name, N'未知工序') AS processName,
-- 汇总计划与完成数量
CAST(SUM(ISNULL(p.plan_amount, 0)) AS DECIMAL(18,4)) AS planQty,
CAST(SUM(ISNULL(p.complete_amount, 0)) AS DECIMAL(18,4)) AS completedQty,
CAST(SUM(ISNULL(p.plan_amount, 0) - ISNULL(p.complete_amount, 0)) AS DECIMAL(18,4)) AS uncompletedQty,
-- 完成率(数值 & 展示)
CAST(
CASE WHEN SUM(ISNULL(p.plan_amount, 0)) > 0
THEN (CAST(SUM(ISNULL(p.complete_amount, 0)) AS DECIMAL(18,6)) / CAST(SUM(ISNULL(p.plan_amount, 0)) AS DECIMAL(18,6))) * 100
ELSE 0 END
AS DECIMAL(10,2)) AS completionRateNum,
CONCAT(
CAST(
CASE WHEN SUM(ISNULL(p.plan_amount, 0)) > 0
THEN (CAST(SUM(ISNULL(p.complete_amount, 0)) AS DECIMAL(18,6)) / CAST(SUM(ISNULL(p.plan_amount, 0)) AS DECIMAL(18,6))) * 100
ELSE 0 END
AS DECIMAL(10,2)
), '%') AS completionRate
FROM ${planTableName} AS p
LEFT JOIN prod_base_process_info AS pproc ON pproc.process_id = p.process_id
LEFT JOIN base_material_info AS bmi ON bmi.material_id = p.material_id
]]>
<where>
<if test="map.beginDate != null and map.beginDate != '' and map.endDate != null and map.endDate != ''">
AND FORMAT(p.plan_begin_time, 'yyyy-MM-dd') BETWEEN #{map.beginDate} AND #{map.endDate}
</if>
<if test="map.processId != null and map.processId != ''">
AND p.process_id = #{map.processId}
</if>
<if test="map.machineId != null and map.machineId != ''">
AND p.release_id = #{map.machineId}
</if>
<if test="map.shiftId != null and map.shiftId != ''">
AND p.shift_id = #{map.shiftId}
</if>
<if test="map.classTeamId != null and map.classTeamId != ''">
AND p.class_team_id = #{map.classTeamId}
</if>
<if test="map.planCode != null and map.planCode != ''">
AND p.plan_code LIKE CONCAT('%', #{map.planCode}, '%')
</if>
<if test="map.materialName != null and map.materialName != ''">
AND bmi.material_name LIKE CONCAT('%', #{map.materialName}, '%')
</if>
</where>
<![CDATA[
GROUP BY ISNULL(pproc.process_name, N'未知工序')
ORDER BY completionRateNum DESC, processName
]]>
</select>
</mapper> </mapper>

Loading…
Cancel
Save