|
|
|
|
@ -0,0 +1,734 @@
|
|
|
|
|
<?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="org.dromara.mes.mapper.ProdReportMapper">
|
|
|
|
|
|
|
|
|
|
<select id="planCompletionRateReportVoList" resultType="org.dromara.mes.domain.vo.PlanCompletionRateReportVo">
|
|
|
|
|
SELECT bmi.material_name materialName,
|
|
|
|
|
CAST(SUM(t.plan_amount) AS DECIMAL(10, 2)) planNumber,
|
|
|
|
|
CAST(SUM(t.complete_amount) AS DECIMAL(10, 2)) actualNumber,
|
|
|
|
|
CAST(SUM(t.complete_amount - t.plan_amount) AS DECIMAL(10, 2)) deviationNumber,
|
|
|
|
|
CONCAT(CAST((SUM(t.complete_amount) / SUM(t.plan_amount))
|
|
|
|
|
* 100 AS DECIMAL(10, 2)), '%') completionRate
|
|
|
|
|
FROM ${tableName} t
|
|
|
|
|
LEFT JOIN base_material_info bmi on bmi.material_id = t.material_id
|
|
|
|
|
<where>
|
|
|
|
|
<if test="map.beginDate != null and map.beginDate != '' and map.endDate != null and map.endDate != ''">
|
|
|
|
|
AND FORMAT(t.plan_begin_time, 'yyyy-MM-dd') BETWEEN #{map.beginDate} AND #{map.endDate}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.processId != null and map.processId != ''">
|
|
|
|
|
AND t.process_id = #{map.processId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.machineId != null and map.machineId != ''">
|
|
|
|
|
AND t.release_id = #{map.machineId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.shiftId != null and map.shiftId != ''">
|
|
|
|
|
AND t.shift_id = #{map.shiftId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.classTeamId != null and map.classTeamId != ''">
|
|
|
|
|
AND t.class_team_id = #{map.classTeamId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.planCode != null and map.planCode != ''">
|
|
|
|
|
AND t.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>
|
|
|
|
|
GROUP BY bmi.material_name
|
|
|
|
|
ORDER BY materialName
|
|
|
|
|
</select>
|
|
|
|
|
|
|
|
|
|
<select id="planCompletionContrastReportVoList"
|
|
|
|
|
resultType="org.dromara.mes.domain.vo.PlanCompletionContrastReportVo">
|
|
|
|
|
WITH aggregated_data AS (SELECT t.tenant_id, bmi.material_name AS materialName,
|
|
|
|
|
SUM(IIF(FORMAT(t.plan_begin_time, 'yyyy-MM-dd') = FORMAT(CAST(#{map.beginDate} AS DATETIME), 'yyyy-MM-dd'), t.plan_amount, 0)) AS
|
|
|
|
|
dayPlanNumber,
|
|
|
|
|
SUM(IIF(FORMAT(t.plan_begin_time, 'yyyy-MM-dd') = FORMAT(CAST(#{map.beginDate} AS DATETIME), 'yyyy-MM-dd'), t.complete_amount, 0))
|
|
|
|
|
AS dayActualNumber,
|
|
|
|
|
SUM(IIF(FORMAT(t.plan_begin_time, 'yyyy-MM') = FORMAT(CAST(#{map.beginDate} AS DATETIME), 'yyyy-MM'), t.plan_amount, 0)) AS
|
|
|
|
|
monthPlanNumber,
|
|
|
|
|
SUM(IIF(FORMAT(t.plan_begin_time, 'yyyy-MM') = FORMAT(CAST(#{map.beginDate} AS DATETIME), 'yyyy-MM'), t.complete_amount, 0)) AS
|
|
|
|
|
monthActualNumber,
|
|
|
|
|
SUM(IIF(FORMAT(t.plan_begin_time, 'yyyy') = FORMAT(CAST(#{map.beginDate} AS DATETIME), 'yyyy'), t.plan_amount, 0)) AS
|
|
|
|
|
yearPlanNumber,
|
|
|
|
|
SUM(IIF(FORMAT(t.plan_begin_time, 'yyyy') = FORMAT(CAST(#{map.beginDate} AS DATETIME), 'yyyy'), t.complete_amount, 0)) AS
|
|
|
|
|
yearActualNumber
|
|
|
|
|
FROM ${tableName} t
|
|
|
|
|
LEFT JOIN base_material_info bmi ON bmi.material_id = t.material_id
|
|
|
|
|
<where>
|
|
|
|
|
<if test="map.beginDate != null and map.beginDate != ''">
|
|
|
|
|
AND FORMAT(t.plan_begin_time, 'yyyy-MM-dd') BETWEEN #{map.beginDate} AND #{map.beginDate}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.processId != null and map.processId != ''">
|
|
|
|
|
AND t.process_id = #{map.processId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.machineId != null and map.machineId != ''">
|
|
|
|
|
AND t.release_id = #{map.machineId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.shiftId != null and map.shiftId != ''">
|
|
|
|
|
AND t.shift_id = #{map.shiftId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.classTeamId != null and map.classTeamId != ''">
|
|
|
|
|
AND t.class_team_id = #{map.classTeamId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.planCode != null and map.planCode != ''">
|
|
|
|
|
AND t.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>
|
|
|
|
|
GROUP BY t.tenant_id, bmi.material_name)
|
|
|
|
|
SELECT materialName,
|
|
|
|
|
-- 当天数据
|
|
|
|
|
CAST(dayPlanNumber AS DECIMAL(10, 2)) AS dayPlanNumber,
|
|
|
|
|
CAST(dayActualNumber AS DECIMAL(10, 2)) AS dayActualNumber,
|
|
|
|
|
CAST(dayActualNumber - dayPlanNumber AS DECIMAL(10, 2)) AS dayDeviationNumber,
|
|
|
|
|
CONCAT(CAST(IIF(dayPlanNumber = 0, 0, (dayActualNumber * 100.0 / dayPlanNumber)) AS DECIMAL(10, 2)),
|
|
|
|
|
'%') AS dayCompletionRate,
|
|
|
|
|
-- 当月数据
|
|
|
|
|
CAST(monthPlanNumber AS DECIMAL(10, 2)) AS monthPlanNumber,
|
|
|
|
|
CAST(monthActualNumber AS DECIMAL(10, 2)) AS monthActualNumber,
|
|
|
|
|
CAST(monthActualNumber - monthPlanNumber AS DECIMAL(10, 2)) AS monthDeviationNumber,
|
|
|
|
|
CONCAT(CAST(IIF(monthPlanNumber = 0, 0, (monthActualNumber * 100.0 / monthPlanNumber)) AS DECIMAL(10, 2)),
|
|
|
|
|
'%') AS monthCompletionRate,
|
|
|
|
|
-- 当年数据
|
|
|
|
|
CAST(yearPlanNumber AS DECIMAL(10, 2)) AS yearPlanNumber,
|
|
|
|
|
CAST(yearActualNumber AS DECIMAL(10, 2)) AS yearActualNumber,
|
|
|
|
|
CAST(yearActualNumber - yearPlanNumber AS DECIMAL(10, 2)) AS yearDeviationNumber,
|
|
|
|
|
CONCAT(CAST(IIF(yearPlanNumber = 0, 0, (yearActualNumber * 100.0 / yearPlanNumber)) AS DECIMAL(10, 2)),
|
|
|
|
|
'%') AS yearCompletionRate
|
|
|
|
|
FROM aggregated_data
|
|
|
|
|
ORDER BY materialName
|
|
|
|
|
</select>
|
|
|
|
|
|
|
|
|
|
<select id="designDailyOutputInformation" resultType="java.util.HashMap">
|
|
|
|
|
SELECT CONVERT(DATE, t.real_end_time) productionDate,
|
|
|
|
|
COUNT(*) completeAmount
|
|
|
|
|
FROM ${tableName} t
|
|
|
|
|
LEFT JOIN base_material_info bmi ON bmi.material_id = t.material_id
|
|
|
|
|
WHERE real_end_time IS NOT NULL
|
|
|
|
|
<if test="map.beginDate != null and map.beginDate != '' and map.endDate != null and map.endDate != ''">
|
|
|
|
|
AND FORMAT(t.real_end_time, 'yyyy-MM-dd') BETWEEN #{map.beginDate} AND #{map.endDate}
|
|
|
|
|
</if>
|
|
|
|
|
GROUP BY CONVERT(DATE, t.real_end_time)
|
|
|
|
|
ORDER BY productionDate
|
|
|
|
|
</select>
|
|
|
|
|
|
|
|
|
|
<select id="yieldSummaryByMachine" resultType="java.util.HashMap">
|
|
|
|
|
SELECT bm.machine_name AS machineName,
|
|
|
|
|
COUNT(1) AS totalCount,
|
|
|
|
|
SUM(CASE WHEN (UPPER(t.scan_result) IN ('OK','PASS') OR t.scan_result IN (N'通过')) THEN 1 ELSE 0 END) AS okCount,
|
|
|
|
|
SUM(CASE WHEN t.scan_result IS NULL THEN 0 WHEN (UPPER(t.scan_result) IN ('OK','PASS') OR t.scan_result IN (N'通过')) THEN 0 ELSE 1 END) AS ngCount,
|
|
|
|
|
CAST(IIF(COUNT(1) = 0, 0, (SUM(CASE WHEN (UPPER(t.scan_result) IN ('OK','PASS') OR t.scan_result IN (N'通过')) THEN 1 ELSE 0 END) * 100.0 / COUNT(1))) AS DECIMAL(10,2)) AS yieldRateNum,
|
|
|
|
|
CONCAT(CAST(IIF(COUNT(1) = 0, 0, (SUM(CASE WHEN (UPPER(t.scan_result) IN ('OK','PASS') OR t.scan_result IN (N'通过')) THEN 1 ELSE 0 END) * 100.0 / COUNT(1))) AS DECIMAL(10,2)), '%') AS yieldRate
|
|
|
|
|
FROM prod_output_scan_info t
|
|
|
|
|
LEFT JOIN prod_base_machine_info bm ON bm.machine_id = t.machine_id
|
|
|
|
|
LEFT JOIN prod_base_process_info pi ON pi.process_id = t.process_id
|
|
|
|
|
LEFT JOIN base_material_info bmi ON bmi.material_id = t.materiel_id
|
|
|
|
|
<where>
|
|
|
|
|
<if test="map.beginDate != null and map.beginDate != '' and map.endDate != null and map.endDate != ''">
|
|
|
|
|
AND FORMAT(t.create_time, 'yyyy-MM-dd') BETWEEN #{map.beginDate} AND #{map.endDate}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.processId != null and map.processId != ''">
|
|
|
|
|
AND t.process_id = #{map.processId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.machineId != null and map.machineId != ''">
|
|
|
|
|
AND t.machine_id = #{map.machineId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.materialName != null and map.materialName != ''">
|
|
|
|
|
AND bmi.material_name LIKE CONCAT('%', #{map.materialName}, '%')
|
|
|
|
|
</if>
|
|
|
|
|
</where>
|
|
|
|
|
GROUP BY bm.machine_name
|
|
|
|
|
ORDER BY yieldRateNum DESC, machineName
|
|
|
|
|
</select>
|
|
|
|
|
|
|
|
|
|
<select id="yieldTrendByDate" resultType="java.util.HashMap">
|
|
|
|
|
SELECT CONVERT(DATE, t.create_time) AS productionDate,
|
|
|
|
|
COUNT(1) AS totalCount,
|
|
|
|
|
SUM(CASE WHEN (UPPER(t.scan_result) IN ('OK','PASS') OR t.scan_result IN (N'通过')) THEN 1 ELSE 0 END) AS okCount,
|
|
|
|
|
SUM(CASE WHEN t.scan_result IS NULL THEN 0 WHEN (UPPER(t.scan_result) IN ('OK','PASS') OR t.scan_result IN (N'通过')) THEN 0 ELSE 1 END) AS ngCount,
|
|
|
|
|
CAST(IIF(COUNT(1) = 0, 0, (SUM(CASE WHEN (UPPER(t.scan_result) IN ('OK','PASS') OR t.scan_result IN (N'通过')) THEN 1 ELSE 0 END) * 100.0 / COUNT(1))) AS DECIMAL(10,2)) AS yieldRateNum,
|
|
|
|
|
CONCAT(CAST(IIF(COUNT(1) = 0, 0, (SUM(CASE WHEN (UPPER(t.scan_result) IN ('OK','PASS') OR t.scan_result IN (N'通过')) THEN 1 ELSE 0 END) * 100.0 / COUNT(1))) AS DECIMAL(10,2)), '%') AS yieldRate
|
|
|
|
|
FROM prod_output_scan_info t
|
|
|
|
|
LEFT JOIN prod_base_machine_info bm ON bm.machine_id = t.machine_id
|
|
|
|
|
LEFT JOIN prod_base_process_info pi ON pi.process_id = t.process_id
|
|
|
|
|
LEFT JOIN base_material_info bmi ON bmi.material_id = t.materiel_id
|
|
|
|
|
<where>
|
|
|
|
|
<if test="map.beginDate != null and map.beginDate != '' and map.endDate != null and map.endDate != ''">
|
|
|
|
|
AND FORMAT(t.create_time, 'yyyy-MM-dd') BETWEEN #{map.beginDate} AND #{map.endDate}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.processId != null and map.processId != ''">
|
|
|
|
|
AND t.process_id = #{map.processId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.machineId != null and map.machineId != ''">
|
|
|
|
|
AND t.machine_id = #{map.machineId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.materialName != null and map.materialName != ''">
|
|
|
|
|
AND bmi.material_name LIKE CONCAT('%', #{map.materialName}, '%')
|
|
|
|
|
</if>
|
|
|
|
|
</where>
|
|
|
|
|
GROUP BY CONVERT(DATE, t.create_time)
|
|
|
|
|
ORDER BY productionDate
|
|
|
|
|
</select>
|
|
|
|
|
|
|
|
|
|
<!-- 班组作业情况报表 -->
|
|
|
|
|
<select id="teamWorkReportList" resultType="org.dromara.mes.domain.vo.TeamWorkReportVo">
|
|
|
|
|
SELECT
|
|
|
|
|
bct.team_name AS teamName,
|
|
|
|
|
pbsi.station_name AS stationName,
|
|
|
|
|
ppd.user_name AS operatorName,
|
|
|
|
|
bmi.material_name AS productName,
|
|
|
|
|
pproc.process_name AS processName,
|
|
|
|
|
CAST(ppd.complete_amount AS DECIMAL(18,4)) AS productionQuantity,
|
|
|
|
|
CAST(ISNULL(qc.qualified_qty, 0) AS DECIMAL(18,4)) AS qualifiedQuantity,
|
|
|
|
|
CAST(ISNULL(qc.unqualified_qty, 0) AS DECIMAL(18,4)) AS unqualifiedQuantity,
|
|
|
|
|
CAST(
|
|
|
|
|
CASE WHEN ISNULL(ppd.complete_amount,0) > 0
|
|
|
|
|
THEN (ISNULL(qc.qualified_qty,0) + 0.0) / (ppd.complete_amount + 0.0) * 100
|
|
|
|
|
ELSE NULL END
|
|
|
|
|
AS DECIMAL(18,4)
|
|
|
|
|
) AS qualifiedRate,
|
|
|
|
|
ppd.real_begin_time AS startTime,
|
|
|
|
|
ppd.real_end_time AS endTime,
|
|
|
|
|
CAST(DATEDIFF(SECOND, ppd.real_begin_time, ppd.real_end_time) / 3600.0 AS DECIMAL(18,4)) AS workHours,
|
|
|
|
|
COALESCE(ppd.remark, ppi.remark) AS remark
|
|
|
|
|
FROM ${detailTableName} AS ppd
|
|
|
|
|
INNER JOIN ${planTableName} AS ppi ON ppi.plan_id = ppd.plan_id
|
|
|
|
|
LEFT JOIN base_class_team_info AS bct ON bct.class_team_id = ppd.class_team_id
|
|
|
|
|
LEFT JOIN prod_base_station_info AS pbsi ON pbsi.station_id = bct.station_id
|
|
|
|
|
LEFT JOIN prod_base_process_info AS pproc ON pproc.process_id = ppi.process_id
|
|
|
|
|
LEFT JOIN base_material_info AS bmi ON bmi.material_id = ppi.material_id
|
|
|
|
|
LEFT JOIN (
|
|
|
|
|
SELECT
|
|
|
|
|
plan_detail_id,
|
|
|
|
|
SUM(ISNULL(qualified_qty, 0)) AS qualified_qty,
|
|
|
|
|
SUM(ISNULL(unqualified_qty, 0)) AS unqualified_qty
|
|
|
|
|
FROM qc_inspection_main
|
|
|
|
|
WHERE del_flag = '0'
|
|
|
|
|
GROUP BY plan_detail_id
|
|
|
|
|
) AS qc ON qc.plan_detail_id = ppd.plan_detail_id
|
|
|
|
|
<where>
|
|
|
|
|
-- ppd.real_begin_time IS NOT NULL AND ppd.real_end_time IS NOT NULL
|
|
|
|
|
<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>-->
|
|
|
|
|
<if test="map.machineId != null and map.machineId != ''">
|
|
|
|
|
AND ppi.release_id = #{map.machineId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.shiftId != null and map.shiftId != ''">
|
|
|
|
|
AND ppi.shift_id = #{map.shiftId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.classTeamId != null and map.classTeamId != ''">
|
|
|
|
|
AND ppd.class_team_id = #{map.classTeamId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.planCode != null and map.planCode != ''">
|
|
|
|
|
AND ppi.dispatch_code LIKE CONCAT('%', #{map.planCode}, '%')
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.materialName != null and map.materialName != ''">
|
|
|
|
|
AND bmi.material_name LIKE CONCAT('%', #{map.materialName}, '%')
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.operatorName != null and map.operatorName != ''">
|
|
|
|
|
AND ppd.user_name LIKE CONCAT('%', #{map.operatorName}, '%')
|
|
|
|
|
</if>
|
|
|
|
|
</where>
|
|
|
|
|
ORDER BY ppd.real_begin_time DESC, ppi.plan_id DESC
|
|
|
|
|
</select>
|
|
|
|
|
|
|
|
|
|
<select id="workHourReportList" resultType="org.dromara.mes.domain.vo.WorkHourReportVo">
|
|
|
|
|
SELECT
|
|
|
|
|
ppi.dispatch_code AS dispatchCode,
|
|
|
|
|
bct.team_name AS teamName,
|
|
|
|
|
pbsi.station_name AS stationName,
|
|
|
|
|
bmi.material_name AS materialName,
|
|
|
|
|
pproc.process_name AS processName,
|
|
|
|
|
CAST(ppd.complete_amount AS DECIMAL(18,4)) AS completeAmount,
|
|
|
|
|
CAST(ppd.complete_amount * ISNULL(pproc.production_time, 0) / 3600.0 AS DECIMAL(18,4)) AS standardWorkHour,
|
|
|
|
|
CAST(DATEDIFF(SECOND, ppd.real_begin_time, ppd.real_end_time) / 3600.0 AS DECIMAL(18,4)) AS reportWorkHour,
|
|
|
|
|
CAST(
|
|
|
|
|
CASE
|
|
|
|
|
WHEN DATEDIFF(SECOND, ppd.real_begin_time, ppd.real_end_time) > 0
|
|
|
|
|
THEN (ppd.complete_amount + 0.0) / (DATEDIFF(SECOND, ppd.real_begin_time, ppd.real_end_time) / 3600.0)
|
|
|
|
|
ELSE NULL
|
|
|
|
|
END
|
|
|
|
|
AS DECIMAL(18,4)
|
|
|
|
|
) AS productionEfficiency,
|
|
|
|
|
ppi.plan_status AS planStatus,
|
|
|
|
|
COALESCE(ppd.remark, ppi.remark) AS remark
|
|
|
|
|
FROM ${detailTableName} AS ppd
|
|
|
|
|
INNER JOIN ${planTableName} AS ppi ON ppi.plan_id = ppd.plan_id
|
|
|
|
|
LEFT JOIN base_class_team_info AS bct ON bct.class_team_id = ppd.class_team_id
|
|
|
|
|
LEFT JOIN prod_base_station_info AS pbsi ON pbsi.station_id = bct.station_id
|
|
|
|
|
LEFT JOIN prod_base_process_info AS pproc ON pproc.process_id = ppi.process_id
|
|
|
|
|
LEFT JOIN base_material_info AS bmi ON bmi.material_id = ppi.material_id
|
|
|
|
|
<where>
|
|
|
|
|
<!-- ppd.real_begin_time IS NOT NULL AND ppd.real_end_time IS NOT NULL -->
|
|
|
|
|
<!-- ppd.real_begin_time IS NOT NULL AND ppd.real_end_time IS NOT NULL -->
|
|
|
|
|
<if test="map.beginDate != null and map.beginDate != '' and map.endDate != null and map.endDate != ''">
|
|
|
|
|
AND 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>-->
|
|
|
|
|
<if test="map.machineId != null and map.machineId != ''">
|
|
|
|
|
AND ppi.release_id = #{map.machineId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.shiftId != null and map.shiftId != ''">
|
|
|
|
|
AND ppi.shift_id = #{map.shiftId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.classTeamId != null and map.classTeamId != ''">
|
|
|
|
|
AND ppd.class_team_id = #{map.classTeamId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.planCode != null and map.planCode != ''">
|
|
|
|
|
AND ppi.dispatch_code LIKE CONCAT('%', #{map.planCode}, '%')
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.materialName != null and map.materialName != ''">
|
|
|
|
|
AND bmi.material_name LIKE CONCAT('%', #{map.materialName}, '%')
|
|
|
|
|
</if>
|
|
|
|
|
</where>
|
|
|
|
|
ORDER BY ppd.real_begin_time DESC, ppi.plan_id DESC
|
|
|
|
|
</select>
|
|
|
|
|
|
|
|
|
|
<!-- 在制品跟踪报表 - 高性能优化版本(进一步优化:限制工序统计范围到已过滤订单,避免全表扫描) -->
|
|
|
|
|
<select id="wipTrackingReportList" resultType="org.dromara.mes.domain.vo.WipTrackingReportVo">
|
|
|
|
|
WITH Plans AS (
|
|
|
|
|
SELECT p.plan_code, p.tenant_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'
|
|
|
|
|
<if test="map.tenantId != null and map.tenantId != ''">
|
|
|
|
|
AND p.tenant_id = #{map.tenantId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.beginDate != null and map.beginDate != '' and map.endDate != null and map.endDate != ''">
|
|
|
|
|
AND p.plan_begin_time >= CAST(#{map.beginDate} AS DATETIME)
|
|
|
|
|
AND p.plan_begin_time < 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 test="map.materialName != null and map.materialName != ''">
|
|
|
|
|
AND m.material_name LIKE CONCAT('%', #{map.materialName}, '%')
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.materialCode != null and map.materialCode != ''">
|
|
|
|
|
AND m.material_code LIKE CONCAT('%', #{map.materialCode}, '%')
|
|
|
|
|
</if>
|
|
|
|
|
GROUP BY p.plan_code, p.tenant_id
|
|
|
|
|
),
|
|
|
|
|
ProcessRows AS (
|
|
|
|
|
-- 订单范围内的所有工序计划行(UNION ALL 提升性能)
|
|
|
|
|
SELECT p2.plan_code, 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 Plans pl ON pl.plan_code = p2.plan_code AND pl.tenant_id = p2.tenant_id
|
|
|
|
|
|
|
|
|
|
UNION ALL
|
|
|
|
|
|
|
|
|
|
SELECT p3.plan_code, 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 Plans pl ON pl.plan_code = p3.plan_code AND pl.tenant_id = p3.tenant_id
|
|
|
|
|
|
|
|
|
|
UNION ALL
|
|
|
|
|
|
|
|
|
|
SELECT p4.plan_code, 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 Plans pl ON pl.plan_code = p4.plan_code AND pl.tenant_id = p4.tenant_id
|
|
|
|
|
),
|
|
|
|
|
DistinctProcess AS (
|
|
|
|
|
-- 按计划+工序聚合为唯一工序,避免同一工序多行导致工序数偏大
|
|
|
|
|
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
|
|
|
|
|
NULL AS productOrderId,
|
|
|
|
|
'' AS orderCode,
|
|
|
|
|
oa.plan_code AS planCode,
|
|
|
|
|
m.material_code AS materialCode,
|
|
|
|
|
m.material_name AS materialName,
|
|
|
|
|
ISNULL(m.material_spec, '') AS materialSpec,
|
|
|
|
|
CAST(oa.plan_amount AS DECIMAL(18,2)) AS planAmount,
|
|
|
|
|
CAST(ISNULL(oa.plan_amount,0) - ISNULL(oa.complete_amount,0) AS DECIMAL(18,2)) AS wipAmount,
|
|
|
|
|
CAST(ISNULL(oa.complete_amount,0) AS DECIMAL(18,2)) AS completeAmount,
|
|
|
|
|
oa.plan_begin_time AS planBeginTime,
|
|
|
|
|
oa.real_begin_time AS realBeginTime,
|
|
|
|
|
oa.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 oa.plan_amount > 0
|
|
|
|
|
THEN (CAST(ISNULL(oa.complete_amount,0) AS DECIMAL(18,6)) / CAST(oa.plan_amount AS DECIMAL(18,6))) * 100
|
|
|
|
|
ELSE 0
|
|
|
|
|
END
|
|
|
|
|
AS DECIMAL(10,2)), '%'
|
|
|
|
|
) AS overallProgress,
|
|
|
|
|
-- 进度状态判断:延期或正常
|
|
|
|
|
CASE
|
|
|
|
|
WHEN oa.plan_end_time IS NOT NULL AND GETDATE() > oa.plan_end_time AND ISNULL(oa.complete_amount,0) < oa.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 oa.plan_amount > 0
|
|
|
|
|
THEN (CAST(ISNULL(oa.complete_amount,0) AS DECIMAL(18,6)) / CAST(oa.plan_amount AS DECIMAL(18,6))) * 100
|
|
|
|
|
ELSE 0
|
|
|
|
|
END
|
|
|
|
|
AS DECIMAL(10,2)) AS overallProgressNum
|
|
|
|
|
FROM PlanAgg oa
|
|
|
|
|
INNER JOIN base_material_info m ON m.material_id = oa.material_id
|
|
|
|
|
LEFT JOIN ProcessStats ps ON ps.plan_code = oa.plan_code AND ps.tenant_id = oa.tenant_id
|
|
|
|
|
<where>
|
|
|
|
|
<!-- 进度状态过滤单独保留在最终结果上 -->
|
|
|
|
|
<if test="map.progressStatus != null and map.progressStatus != ''">
|
|
|
|
|
AND CASE
|
|
|
|
|
WHEN oa.plan_end_time IS NOT NULL AND GETDATE() > oa.plan_end_time AND ISNULL(oa.complete_amount,0) < oa.plan_amount
|
|
|
|
|
THEN '延期'
|
|
|
|
|
ELSE '正常'
|
|
|
|
|
END = #{map.progressStatus}
|
|
|
|
|
</if>
|
|
|
|
|
</where>
|
|
|
|
|
-- 为避免首屏仅出现以 'PLAN' 开头的计划编号(字符串排序导致),
|
|
|
|
|
-- 改为按时间优先降序,其次按计划编号升序,确保不同编码规则的计划均能出现在第一页
|
|
|
|
|
ORDER BY oa.plan_begin_time DESC, oa.real_begin_time DESC, oa.plan_code ASC
|
|
|
|
|
</select>
|
|
|
|
|
|
|
|
|
|
<!-- 在制品跟踪报表总数(简化版 count):避免复杂 CTE/聚合,保持与筛选条件一致 -->
|
|
|
|
|
<select id="wipTrackingReportCount" resultType="java.lang.Long">
|
|
|
|
|
WITH Plans AS (
|
|
|
|
|
SELECT p.plan_code, p.tenant_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'
|
|
|
|
|
<if test="map.tenantId != null and map.tenantId != ''">
|
|
|
|
|
AND p.tenant_id = #{map.tenantId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.beginDate != null and map.beginDate != '' and map.endDate != null and map.endDate != ''">
|
|
|
|
|
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 test="map.materialName != null and map.materialName != ''">
|
|
|
|
|
AND m.material_name LIKE CONCAT('%', #{map.materialName}, '%')
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.materialCode != null and map.materialCode != ''">
|
|
|
|
|
AND m.material_code LIKE CONCAT('%', #{map.materialCode}, '%')
|
|
|
|
|
</if>
|
|
|
|
|
GROUP BY p.plan_code, p.tenant_id
|
|
|
|
|
),
|
|
|
|
|
PlanAgg AS (
|
|
|
|
|
SELECT
|
|
|
|
|
p.plan_code,
|
|
|
|
|
p.tenant_id,
|
|
|
|
|
MAX(p.plan_code) AS plan_code,
|
|
|
|
|
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
|
|
|
|
|
)
|
|
|
|
|
SELECT COUNT(*)
|
|
|
|
|
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 != ''">
|
|
|
|
|
AND CASE
|
|
|
|
|
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 '正常'
|
|
|
|
|
END = #{map.progressStatus}
|
|
|
|
|
</if>
|
|
|
|
|
</select>
|
|
|
|
|
|
|
|
|
|
<!-- (已清理)订单维度的工序进度查询已移除,统一按 plan_code 维度处理 -->
|
|
|
|
|
|
|
|
|
|
<!-- 获取计划的工序进度详情(按planCode单条) -->
|
|
|
|
|
<select id="getPlanProcessProgress" resultType="org.dromara.mes.domain.vo.ProcessProgressVo">
|
|
|
|
|
SELECT
|
|
|
|
|
p.plan_code AS planCode,
|
|
|
|
|
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,
|
|
|
|
|
bmi.material_name AS materialName,
|
|
|
|
|
bmi.material_code AS materialCode
|
|
|
|
|
FROM ${planTableName} p
|
|
|
|
|
LEFT JOIN prod_base_process_info pr ON pr.process_id = p.process_id
|
|
|
|
|
LEFT JOIN base_material_info bmi ON bmi.material_id = p.material_id
|
|
|
|
|
WHERE p.plan_code = #{planCode}
|
|
|
|
|
ORDER BY p.process_order
|
|
|
|
|
</select>
|
|
|
|
|
|
|
|
|
|
<!-- 批量获取计划的工序进度详情(按planCode批量) -->
|
|
|
|
|
<select id="getPlansProcessProgressBatch" resultType="org.dromara.mes.domain.vo.ProcessProgressVo">
|
|
|
|
|
SELECT
|
|
|
|
|
p.plan_code AS planCode,
|
|
|
|
|
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,
|
|
|
|
|
bmi.material_name AS materialName,
|
|
|
|
|
bmi.material_code AS materialCode
|
|
|
|
|
FROM ${planTableName} p
|
|
|
|
|
LEFT JOIN prod_base_process_info pr ON pr.process_id = p.process_id
|
|
|
|
|
LEFT JOIN base_material_info bmi ON bmi.material_id = p.material_id
|
|
|
|
|
WHERE p.plan_code IN
|
|
|
|
|
<foreach collection="planCodes" item="code" open="(" separator="," close=")">
|
|
|
|
|
#{code}
|
|
|
|
|
</foreach>
|
|
|
|
|
<if test="tenantId != null"> AND p.tenant_id = #{tenantId} </if>
|
|
|
|
|
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>
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
<!-- 小时产量统计(按扫描时间小时分桶,来源于生产产出扫描表,不依赖QC质检表) -->
|
|
|
|
|
<select id="hourlyOutputByHour" resultType="java.util.HashMap">
|
|
|
|
|
SELECT
|
|
|
|
|
CONVERT(DATE, t.create_time) AS productionDate,
|
|
|
|
|
RIGHT('00' + CAST(DATEPART(HOUR, t.create_time) AS VARCHAR(2)), 2) + ':00' AS hourSlot,
|
|
|
|
|
CAST(COUNT(1) AS DECIMAL(18,4)) AS productionQuantity,
|
|
|
|
|
CAST(SUM(CASE WHEN (UPPER(t.scan_result) IN ('OK','PASS') OR t.scan_result IN (N'通过')) THEN 1 ELSE 0 END) AS DECIMAL(18,4)) AS qualifiedQuantity,
|
|
|
|
|
CAST(SUM(CASE WHEN t.scan_result IS NULL THEN 0 WHEN (UPPER(t.scan_result) IN ('OK','PASS') OR t.scan_result IN (N'通过')) THEN 0 ELSE 1 END) AS DECIMAL(18,4)) AS unqualifiedQuantity
|
|
|
|
|
FROM prod_output_scan_info t
|
|
|
|
|
LEFT JOIN ${planTableName} ppi
|
|
|
|
|
ON ppi.process_id = t.process_id
|
|
|
|
|
AND ppi.release_id = t.machine_id
|
|
|
|
|
AND t.create_time >= COALESCE(ppi.real_begin_time, ppi.plan_begin_time)
|
|
|
|
|
AND t.create_time < COALESCE(ppi.real_end_time, ppi.plan_end_time, DATEADD(day, 1, COALESCE(ppi.real_begin_time, ppi.plan_begin_time)))
|
|
|
|
|
LEFT JOIN base_material_info bmi ON bmi.material_id = t.materiel_id
|
|
|
|
|
<where>
|
|
|
|
|
<if test="map.beginDate != null and map.beginDate != '' and map.endDate != null and map.endDate != ''">
|
|
|
|
|
AND t.create_time >= CAST(#{map.beginDate} AS DATETIME)
|
|
|
|
|
AND t.create_time < DATEADD(day, 1, CAST(#{map.endDate} AS DATETIME))
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.processId != null and map.processId != ''">
|
|
|
|
|
AND t.process_id = #{map.processId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.machineId != null and map.machineId != ''">
|
|
|
|
|
AND t.machine_id = #{map.machineId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.shiftId != null and map.shiftId != ''">
|
|
|
|
|
AND ppi.shift_id = #{map.shiftId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.classTeamId != null and map.classTeamId != ''">
|
|
|
|
|
AND ppi.class_team_id = #{map.classTeamId}
|
|
|
|
|
</if>
|
|
|
|
|
<if test="map.materialName != null and map.materialName != ''">
|
|
|
|
|
AND bmi.material_name LIKE CONCAT('%', #{map.materialName}, '%')
|
|
|
|
|
</if>
|
|
|
|
|
</where>
|
|
|
|
|
GROUP BY CONVERT(DATE, t.create_time), DATEPART(HOUR, t.create_time)
|
|
|
|
|
ORDER BY productionDate, DATEPART(HOUR, t.create_time)
|
|
|
|
|
</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>
|