ALTER PROCEDURE [dbo].[sp_calc_dms_report_device_efficiency] @StatDate DATE, @TenantId VARCHAR(64) = '000000', @WorkshopId BIGINT = NULL, @ClassTeamId BIGINT = NULL, @ShiftId BIGINT = NULL AS BEGIN SET NOCOUNT ON; -- 统计日期缺省处理:为空或占位值(1900-01-01)时,默认使用当天日期 IF @StatDate IS NULL OR @StatDate = '1900-01-01' BEGIN SET @StatDate = CAST(GETDATE() AS DATE); END -- 基本范围校验(DATE 支持 0001-01-01 至 9999-12-31) IF @StatDate < '0001-01-01' OR @StatDate > '9999-12-31' BEGIN RAISERROR('StatDate out of range for date', 16, 1); RETURN; END DECLARE @Start DATETIME2(0) = CAST(@StatDate AS DATETIME2(0)); DECLARE @End DATETIME2(0) = DATEADD(DAY, 1, @Start); -- 调试:打印关键入参与时间窗 PRINT N'[sp_calc_dms_report_device_efficiency] 调试开始'; PRINT N'参数 StatDate=' + CONVERT(varchar(10), @StatDate, 120) + N'; Start=' + CONVERT(varchar(19), @Start, 120) + N'; End=' + CONVERT(varchar(19), @End, 120); -- 归一化租户号:若为空字符串或 NULL,则使用默认 '000000' IF @TenantId IS NULL OR LTRIM(RTRIM(@TenantId)) = '' SET @TenantId = '000000'; PRINT N'租户 TenantId=' + @TenantId; -- 将传入维度参数中的 0 归一化为 NULL(表示不筛选) IF @WorkshopId = 0 SET @WorkshopId = NULL; IF @ClassTeamId = 0 SET @ClassTeamId = NULL; IF @ShiftId = 0 SET @ShiftId = NULL; PRINT N'过滤维度(归一化) WorkshopId=' + COALESCE(CONVERT(varchar(20), @WorkshopId), N'NULL') + N', ClassTeamId=' + COALESCE(CONVERT(varchar(20), @ClassTeamId), N'NULL') + N', ShiftId=' + COALESCE(CONVERT(varchar(20), @ShiftId), N'NULL'); -- 删除当日同维度既有数据,避免重复(需在CTE之前执行,否则CTE作用域只对紧邻下一条语句有效) DELETE t FROM dbo.dms_report_device_efficiency t WHERE t.stat_date = @StatDate AND t.tenant_id = @TenantId AND (@WorkshopId IS NULL OR t.workshop_id = @WorkshopId) AND (@ClassTeamId IS NULL OR t.class_team_id = @ClassTeamId) AND (@ShiftId IS NULL OR t.shift_id = @ShiftId); -- 维度过滤条件(改为基于 dms_realtime_status_history 的相邻记录时间窗) ;WITH hist AS ( SELECT h.tenant_id, h.machine_id, h.status_code, h.status_name, h.status_value, h.sync_time, LEAD(h.sync_time) OVER (PARTITION BY h.machine_id ORDER BY h.sync_time) AS next_sync_time FROM dbo.dms_realtime_status_history h WITH (NOLOCK) WHERE h.tenant_id = @TenantId ), state_raw AS ( SELECT h.tenant_id, m.workshop_id, CAST(NULL AS BIGINT) AS class_team_id, CAST(NULL AS BIGINT) AS shift_id, h.machine_id, -- 将实时状态映射到运行类型:0运行、1待机、2故障、3停机、4调试 CASE WHEN UPPER(h.status_code) IN ('RUN','RUNNING') OR h.status_name LIKE N'%运行%' OR UPPER(coalesce(h.status_value,'')) IN ('1','RUN','RUNNING') THEN '0' WHEN UPPER(h.status_code) IN ('IDLE','STANDBY') OR h.status_name LIKE N'%待机%' THEN '1' WHEN UPPER(h.status_code) IN ('FAULT','ALARM') OR h.status_name LIKE N'%故障%' THEN '2' WHEN UPPER(h.status_code) IN ('STOP','OFF','SHUTDOWN') OR h.status_name LIKE N'%停机%' THEN '3' WHEN UPPER(h.status_code) IN ('DEBUG','SETUP') OR h.status_name LIKE N'%调试%' THEN '4' ELSE NULL END AS state_type, -- 计算与统计日期的时间窗重叠秒数(以相邻快照作为区间) CASE WHEN COALESCE(h.next_sync_time, @End) > h.sync_time THEN DATEDIFF_BIG(SECOND, CASE WHEN h.sync_time < @Start THEN @Start ELSE h.sync_time END, CASE WHEN COALESCE(h.next_sync_time, @End) > @End THEN @End ELSE COALESCE(h.next_sync_time, @End) END) ELSE 0 END AS overlap_seconds FROM hist h LEFT JOIN dbo.prod_base_machine_info m WITH (NOLOCK) ON m.machine_id = h.machine_id WHERE h.sync_time < @End AND COALESCE(h.next_sync_time, @End) > @Start AND (@WorkshopId IS NULL OR m.workshop_id = @WorkshopId) -- 注:class_team_id 与 shift_id 无法从实时状态历史推断,保留为 NULL ), state_hours AS ( SELECT tenant_id, workshop_id, class_team_id, shift_id, machine_id, SUM(CASE WHEN state_type = '4' THEN overlap_seconds ELSE 0 END) / 3600.0 AS debug_hours, SUM(CASE WHEN state_type = '0' THEN overlap_seconds ELSE 0 END) / 3600.0 AS run_hours, SUM(CASE WHEN state_type = '1' THEN overlap_seconds ELSE 0 END) / 3600.0 AS standby_hours, SUM(CASE WHEN state_type = '2' THEN overlap_seconds ELSE 0 END) / 3600.0 AS fault_hours, SUM(CASE WHEN state_type = '3' THEN overlap_seconds ELSE 0 END) / 3600.0 AS shutdown_hours FROM state_raw WHERE overlap_seconds > 0 GROUP BY tenant_id, workshop_id, class_team_id, shift_id, machine_id ), output_cte AS ( -- 产量来源:prod_input_scan_info(以 feeding_time 优先,其次 create_time),按机台/车间维度计数 SELECT p.tenant_id, m.workshop_id, CAST(NULL AS BIGINT) AS class_team_id, CAST(NULL AS BIGINT) AS shift_id, p.machine_id, COUNT(1) AS output_qty FROM dbo.prod_input_scan_info p WITH (NOLOCK) LEFT JOIN dbo.prod_base_machine_info m WITH (NOLOCK) ON m.machine_id = p.machine_id WHERE COALESCE(p.feeding_time, p.create_time) >= @Start AND COALESCE(p.feeding_time, p.create_time) < @End AND p.tenant_id = @TenantId AND (@WorkshopId IS NULL OR m.workshop_id = @WorkshopId) GROUP BY p.tenant_id, m.workshop_id, p.machine_id ), std_cte AS ( -- 标准机时来源:机台工序关联 + 工序单位生产时间(秒)换算小时 SELECT mp.machine_id, CAST(ISNULL(pi.production_time, 0) / 3600.0 AS decimal(18,6)) AS process_std_machine_hours FROM dbo.prod_base_machine_process mp WITH (NOLOCK) LEFT JOIN dbo.prod_base_process_info pi WITH (NOLOCK) ON pi.process_id = mp.process_id WHERE mp.tenant_id = @TenantId ), agg AS ( SELECT sh.tenant_id, @StatDate AS stat_date, sh.workshop_id, sh.class_team_id, sh.shift_id, sh.machine_id, w.workshop_name, ct.team_name AS class_team_name, sft.shift_name, mi.machine_name, ISNULL(o.output_qty, 0) AS output_qty, ISNULL(s.process_std_machine_hours, 0) AS process_std_machine_hours, sh.debug_hours, sh.run_hours, sh.standby_hours, sh.fault_hours, sh.shutdown_hours FROM state_hours sh LEFT JOIN output_cte o ON o.tenant_id = sh.tenant_id AND o.workshop_id = sh.workshop_id AND o.class_team_id = sh.class_team_id AND o.shift_id = sh.shift_id AND o.machine_id = sh.machine_id LEFT JOIN std_cte s ON s.machine_id = sh.machine_id LEFT JOIN dbo.prod_base_workshop_info w WITH (NOLOCK) ON w.workshop_id = sh.workshop_id LEFT JOIN dbo.base_class_team_info ct WITH (NOLOCK) ON ct.class_team_id = sh.class_team_id LEFT JOIN dbo.base_shift_info sft WITH (NOLOCK) ON sft.shift_id = sh.shift_id LEFT JOIN dbo.prod_base_machine_info mi WITH (NOLOCK) ON mi.machine_id = sh.machine_id ) -- 将聚合结果落到临时表,便于调试查看 SELECT a.tenant_id, a.stat_date, a.workshop_id, a.class_team_id, a.shift_id, a.machine_id, a.workshop_name, a.class_team_name, a.shift_name, a.machine_name, a.output_qty, a.process_std_machine_hours, CAST(a.debug_hours AS decimal(18,6)) AS debug_hours, CAST(a.run_hours AS decimal(18,6)) AS run_hours, CAST(a.standby_hours AS decimal(18,6)) AS standby_hours, CAST(a.fault_hours AS decimal(18,6)) AS fault_hours, CAST(a.shutdown_hours AS decimal(18,6)) AS shutdown_hours INTO #agg FROM agg a; -- 调试:预览聚合数据结构与部分记录 PRINT N'聚合结果预览(TOP 20)'; SELECT TOP (20) * FROM #agg ORDER BY machine_id; PRINT N'聚合结果概要统计'; SELECT COUNT(*) AS rows, SUM(output_qty) AS sum_output_qty, SUM(process_std_machine_hours) AS sum_std_hours, SUM(run_hours) AS sum_run_hours, SUM(standby_hours) AS sum_standby_hours, SUM(fault_hours) AS sum_fault_hours, SUM(shutdown_hours) AS sum_shutdown_hours FROM #agg; -- 进一步调试:分别查看 state_raw / state_hours 的行数与示例,定位空结果来源 PRINT N'state_raw 行计数与示例(窗口与租户过滤后)'; ;WITH hist2 AS ( SELECT h.tenant_id, h.machine_id, h.status_code, h.status_name, h.status_value, h.sync_time, LEAD(h.sync_time) OVER (PARTITION BY h.machine_id ORDER BY h.sync_time) AS next_sync_time FROM dbo.dms_realtime_status_history h WITH (NOLOCK) WHERE h.tenant_id = @TenantId ), state_raw2 AS ( SELECT h.tenant_id, m.workshop_id, CAST(NULL AS BIGINT) AS class_team_id, CAST(NULL AS BIGINT) AS shift_id, h.machine_id, CASE WHEN UPPER(h.status_code) IN ('RUN','RUNNING') OR h.status_name LIKE N'%运行%' OR UPPER(coalesce(h.status_value,'')) IN ('1','RUN','RUNNING') THEN '0' WHEN UPPER(h.status_code) IN ('IDLE','STANDBY') OR h.status_name LIKE N'%待机%' THEN '1' WHEN UPPER(h.status_code) IN ('FAULT','ALARM') OR h.status_name LIKE N'%故障%' THEN '2' WHEN UPPER(h.status_code) IN ('STOP','OFF','SHUTDOWN') OR h.status_name LIKE N'%停机%' THEN '3' WHEN UPPER(h.status_code) IN ('DEBUG','SETUP') OR h.status_name LIKE N'%调试%' THEN '4' ELSE NULL END AS state_type, CASE WHEN COALESCE(h.next_sync_time, @End) > h.sync_time THEN DATEDIFF_BIG(SECOND, CASE WHEN h.sync_time < @Start THEN @Start ELSE h.sync_time END, CASE WHEN COALESCE(h.next_sync_time, @End) > @End THEN @End ELSE COALESCE(h.next_sync_time, @End) END) ELSE 0 END AS overlap_seconds, h.sync_time, COALESCE(h.next_sync_time, @End) AS next_sync_time FROM hist2 h LEFT JOIN dbo.prod_base_machine_info m WITH (NOLOCK) ON m.machine_id = h.machine_id WHERE h.sync_time < @End AND COALESCE(h.next_sync_time, @End) > @Start AND (@WorkshopId IS NULL OR m.workshop_id = @WorkshopId) ) SELECT COUNT(*) AS state_raw_rows, SUM(CASE WHEN overlap_seconds > 0 THEN 1 ELSE 0 END) AS positive_overlap_rows, COUNT(DISTINCT machine_id) AS distinct_machines FROM state_raw2; ;WITH hist2 AS ( SELECT h.tenant_id, h.machine_id, h.status_code, h.status_name, h.status_value, h.sync_time, LEAD(h.sync_time) OVER (PARTITION BY h.machine_id ORDER BY h.sync_time) AS next_sync_time FROM dbo.dms_realtime_status_history h WITH (NOLOCK) WHERE h.tenant_id = @TenantId ), state_raw2 AS ( SELECT h.tenant_id, m.workshop_id, CAST(NULL AS BIGINT) AS class_team_id, CAST(NULL AS BIGINT) AS shift_id, h.machine_id, CASE WHEN UPPER(h.status_code) IN ('RUN','RUNNING') OR h.status_name LIKE N'%运行%' OR UPPER(coalesce(h.status_value,'')) IN ('1','RUN','RUNNING') THEN '0' WHEN UPPER(h.status_code) IN ('IDLE','STANDBY') OR h.status_name LIKE N'%待机%' THEN '1' WHEN UPPER(h.status_code) IN ('FAULT','ALARM') OR h.status_name LIKE N'%故障%' THEN '2' WHEN UPPER(h.status_code) IN ('STOP','OFF','SHUTDOWN') OR h.status_name LIKE N'%停机%' THEN '3' WHEN UPPER(h.status_code) IN ('DEBUG','SETUP') OR h.status_name LIKE N'%调试%' THEN '4' ELSE NULL END AS state_type, CASE WHEN COALESCE(h.next_sync_time, @End) > h.sync_time THEN DATEDIFF_BIG(SECOND, CASE WHEN h.sync_time < @Start THEN @Start ELSE h.sync_time END, CASE WHEN COALESCE(h.next_sync_time, @End) > @End THEN @End ELSE COALESCE(h.next_sync_time, @End) END) ELSE 0 END AS overlap_seconds, h.sync_time, COALESCE(h.next_sync_time, @End) AS next_sync_time FROM hist2 h LEFT JOIN dbo.prod_base_machine_info m WITH (NOLOCK) ON m.machine_id = h.machine_id WHERE h.sync_time < @End AND COALESCE(h.next_sync_time, @End) > @Start AND (@WorkshopId IS NULL OR m.workshop_id = @WorkshopId) ) SELECT TOP (10) tenant_id, workshop_id, machine_id, state_type, overlap_seconds, sync_time, next_sync_time FROM state_raw2 ORDER BY machine_id, sync_time; PRINT N'state_hours 行计数与示例'; ;WITH hist3 AS ( SELECT h.tenant_id, h.machine_id, h.status_code, h.status_name, h.status_value, h.sync_time, LEAD(h.sync_time) OVER (PARTITION BY h.machine_id ORDER BY h.sync_time) AS next_sync_time FROM dbo.dms_realtime_status_history h WITH (NOLOCK) WHERE h.tenant_id = @TenantId ), state_raw3 AS ( SELECT h.tenant_id, m.workshop_id, CAST(NULL AS BIGINT) AS class_team_id, CAST(NULL AS BIGINT) AS shift_id, h.machine_id, CASE WHEN UPPER(h.status_code) IN ('RUN','RUNNING') OR h.status_name LIKE N'%运行%' OR UPPER(coalesce(h.status_value,'')) IN ('1','RUN','RUNNING') THEN '0' WHEN UPPER(h.status_code) IN ('IDLE','STANDBY') OR h.status_name LIKE N'%待机%' THEN '1' WHEN UPPER(h.status_code) IN ('FAULT','ALARM') OR h.status_name LIKE N'%故障%' THEN '2' WHEN UPPER(h.status_code) IN ('STOP','OFF','SHUTDOWN') OR h.status_name LIKE N'%停机%' THEN '3' WHEN UPPER(h.status_code) IN ('DEBUG','SETUP') OR h.status_name LIKE N'%调试%' THEN '4' ELSE NULL END AS state_type, CASE WHEN COALESCE(h.next_sync_time, @End) > h.sync_time THEN DATEDIFF_BIG(SECOND, CASE WHEN h.sync_time < @Start THEN @Start ELSE h.sync_time END, CASE WHEN COALESCE(h.next_sync_time, @End) > @End THEN @End ELSE COALESCE(h.next_sync_time, @End) END) ELSE 0 END AS overlap_seconds FROM hist3 h LEFT JOIN dbo.prod_base_machine_info m WITH (NOLOCK) ON m.machine_id = h.machine_id WHERE h.sync_time < @End AND COALESCE(h.next_sync_time, @End) > @Start AND (@WorkshopId IS NULL OR m.workshop_id = @WorkshopId) ), state_hours3 AS ( SELECT tenant_id, workshop_id, class_team_id, shift_id, machine_id, SUM(CASE WHEN state_type = '4' THEN overlap_seconds ELSE 0 END) / 3600.0 AS debug_hours, SUM(CASE WHEN state_type = '0' THEN overlap_seconds ELSE 0 END) / 3600.0 AS run_hours, SUM(CASE WHEN state_type = '1' THEN overlap_seconds ELSE 0 END) / 3600.0 AS standby_hours, SUM(CASE WHEN state_type = '2' THEN overlap_seconds ELSE 0 END) / 3600.0 AS fault_hours, SUM(CASE WHEN state_type = '3' THEN overlap_seconds ELSE 0 END) / 3600.0 AS shutdown_hours FROM state_raw3 WHERE overlap_seconds > 0 GROUP BY tenant_id, workshop_id, class_team_id, shift_id, machine_id ) SELECT COUNT(*) AS state_hours_rows, SUM(run_hours) AS sum_run_hours, SUM(standby_hours) AS sum_standby_hours, SUM(fault_hours) AS sum_fault_hours, SUM(shutdown_hours) AS sum_shutdown_hours FROM state_hours3; ;WITH hist3 AS ( SELECT h.tenant_id, h.machine_id, h.status_code, h.status_name, h.status_value, h.sync_time, LEAD(h.sync_time) OVER (PARTITION BY h.machine_id ORDER BY h.sync_time) AS next_sync_time FROM dbo.dms_realtime_status_history h WITH (NOLOCK) WHERE h.tenant_id = @TenantId ), state_raw3 AS ( SELECT h.tenant_id, m.workshop_id, CAST(NULL AS BIGINT) AS class_team_id, CAST(NULL AS BIGINT) AS shift_id, h.machine_id, CASE WHEN UPPER(h.status_code) IN ('RUN','RUNNING') OR h.status_name LIKE N'%运行%' OR UPPER(coalesce(h.status_value,'')) IN ('1','RUN','RUNNING') THEN '0' WHEN UPPER(h.status_code) IN ('IDLE','STANDBY') OR h.status_name LIKE N'%待机%' THEN '1' WHEN UPPER(h.status_code) IN ('FAULT','ALARM') OR h.status_name LIKE N'%故障%' THEN '2' WHEN UPPER(h.status_code) IN ('STOP','OFF','SHUTDOWN') OR h.status_name LIKE N'%停机%' THEN '3' WHEN UPPER(h.status_code) IN ('DEBUG','SETUP') OR h.status_name LIKE N'%调试%' THEN '4' ELSE NULL END AS state_type, CASE WHEN COALESCE(h.next_sync_time, @End) > h.sync_time THEN DATEDIFF_BIG(SECOND, CASE WHEN h.sync_time < @Start THEN @Start ELSE h.sync_time END, CASE WHEN COALESCE(h.next_sync_time, @End) > @End THEN @End ELSE COALESCE(h.next_sync_time, @End) END) ELSE 0 END AS overlap_seconds FROM hist3 h LEFT JOIN dbo.prod_base_machine_info m WITH (NOLOCK) ON m.machine_id = h.machine_id WHERE h.sync_time < @End AND COALESCE(h.next_sync_time, @End) > @Start AND (@WorkshopId IS NULL OR m.workshop_id = @WorkshopId) ), state_hours3 AS ( SELECT tenant_id, workshop_id, class_team_id, shift_id, machine_id, SUM(CASE WHEN state_type = '4' THEN overlap_seconds ELSE 0 END) / 3600.0 AS debug_hours, SUM(CASE WHEN state_type = '0' THEN overlap_seconds ELSE 0 END) / 3600.0 AS run_hours, SUM(CASE WHEN state_type = '1' THEN overlap_seconds ELSE 0 END) / 3600.0 AS standby_hours, SUM(CASE WHEN state_type = '2' THEN overlap_seconds ELSE 0 END) / 3600.0 AS fault_hours, SUM(CASE WHEN state_type = '3' THEN overlap_seconds ELSE 0 END) / 3600.0 AS shutdown_hours FROM state_raw3 WHERE overlap_seconds > 0 GROUP BY tenant_id, workshop_id, class_team_id, shift_id, machine_id ) SELECT TOP (10) tenant_id, workshop_id, machine_id, debug_hours, run_hours, standby_hours, fault_hours, shutdown_hours FROM state_hours3 ORDER BY machine_id; -- 调试:关键数据源与聚合行数计数,定位“插入为0”的原因 PRINT N'历史数据计数(当日窗口)'; SELECT COUNT(*) AS hist_rows, COUNT(DISTINCT h.machine_id) AS hist_machines FROM dbo.dms_realtime_status_history h WHERE h.tenant_id = @TenantId AND h.sync_time >= @Start AND h.sync_time < @End; PRINT N'历史数据示例(TOP 10)'; SELECT TOP (10) h.machine_id, h.status_code, h.status_name, h.status_value, h.sync_time FROM dbo.dms_realtime_status_history h WHERE h.tenant_id = @TenantId AND h.sync_time >= @Start AND h.sync_time < @End ORDER BY h.sync_time; PRINT N'聚合行数统计'; SELECT COUNT(*) AS agg_rows FROM #agg; -- 写入汇总(计算指标) DECLARE @inserted_rows INT; INSERT INTO dbo.dms_report_device_efficiency ( tenant_id, stat_date, workshop_id, class_team_id, shift_id, machine_id, workshop_name, class_team_name, shift_name, machine_name, output_qty, process_std_machine_hours, debug_hours, run_hours, standby_hours, fault_hours, shutdown_hours, output_machine_hours, total_hours, uptime_rate, overall_efficiency, runtime_efficiency, create_time ) SELECT g.tenant_id, g.stat_date, g.workshop_id, g.class_team_id, g.shift_id, g.machine_id, g.workshop_name, g.class_team_name, g.shift_name, g.machine_name, g.output_qty, g.process_std_machine_hours, g.debug_hours, g.run_hours, g.standby_hours, g.fault_hours, g.shutdown_hours, -- 产出机时 CAST(g.output_qty * g.process_std_machine_hours AS decimal(18,6)) AS output_machine_hours, -- 合计时长 CAST(g.run_hours + g.standby_hours + g.fault_hours AS decimal(18,6)) AS total_hours, -- 开机率 CAST((g.run_hours + g.debug_hours) / NULLIF((g.run_hours + g.standby_hours + g.fault_hours), 0) AS decimal(18,6)) AS uptime_rate, -- 综合效率 CAST((g.output_qty * g.process_std_machine_hours) / NULLIF((g.run_hours + g.standby_hours + g.fault_hours + g.shutdown_hours + g.debug_hours), 0) AS decimal(18,6)) AS overall_efficiency, -- 运行效率 CAST((g.output_qty * g.process_std_machine_hours) / NULLIF(g.run_hours, 0) AS decimal(18,6)) AS runtime_efficiency, GETDATE() FROM #agg g; SET @inserted_rows = @@ROWCOUNT; -- 调试:打印插入行数并预览插入数据 PRINT N'插入行数=' + CONVERT(varchar(20), @inserted_rows); SELECT TOP (50) * FROM dbo.dms_report_device_efficiency WHERE stat_date = @StatDate AND tenant_id = @TenantId AND (@WorkshopId IS NULL OR workshop_id = @WorkshopId) AND (@ClassTeamId IS NULL OR class_team_id = @ClassTeamId) AND (@ShiftId IS NULL OR shift_id = @ShiftId) ORDER BY machine_id; END