feat(dms): 设备故障处理记录表(详细追溯)报表实现

- 新增 DmsReportController、DmsReportMapper、DmsReportServiceImpl等类
- 实现设备故障处理记录的查询和导出功能
- 添加 FaultTraceReportBo、FaultTraceReportVo 等数据传输对象
- 编写复杂的 SQL 查询语句,计算产量损失和工单延误数
hwmom-htk
zangch@mesnac.com 5 months ago
parent fea8b1e0a7
commit f2c47f86bd

@ -0,0 +1,42 @@
package org.dromara.dms.controller;
import cn.dev33.satoken.annotation.SaCheckPermission;
import jakarta.validation.constraints.NotNull;
import lombok.RequiredArgsConstructor;
import org.dromara.common.core.domain.R;
import org.dromara.common.excel.utils.ExcelUtil;
import org.dromara.common.log.annotation.Log;
import org.dromara.common.log.enums.BusinessType;
import org.dromara.common.mybatis.core.page.PageQuery;
import org.dromara.common.mybatis.core.page.TableDataInfo;
import org.dromara.dms.domain.bo.FaultTraceReportBo;
import org.dromara.dms.domain.vo.FaultTraceReportVo;
import org.dromara.dms.service.IDmsReportService;
import org.springframework.validation.annotation.Validated;
import org.springframework.web.bind.annotation.*;
import jakarta.servlet.http.HttpServletResponse;
import java.util.List;
@Validated
@RequiredArgsConstructor
@RestController
@RequestMapping("/report/faultTrace")
public class DmsReportController {
private final IDmsReportService dmsReportService;
@SaCheckPermission("dms:report:faultTrace:list")
@GetMapping("/list")
public TableDataInfo<FaultTraceReportVo> list(FaultTraceReportBo bo, PageQuery pageQuery) {
return dmsReportService.queryFaultTrace(bo, pageQuery);
}
@SaCheckPermission("dms:report:faultTrace:export")
@Log(title = "设备故障处理记录表(详细追溯)", businessType = BusinessType.EXPORT)
@PostMapping("/export")
public void export(FaultTraceReportBo bo, HttpServletResponse response) {
List<FaultTraceReportVo> list = dmsReportService.exportFaultTrace(bo);
ExcelUtil.exportExcel(list, "设备故障处理记录表(详细追溯)", FaultTraceReportVo.class, response);
}
}

@ -0,0 +1,48 @@
package org.dromara.dms.domain.bo;
import lombok.Data;
import java.util.Date;
import java.util.Map;
/**
*
*/
@Data
public class FaultTraceReportBo {
/**
* apply_time
*/
private Date startDate;
/**
* apply_time
*/
private Date endDate;
/**
* IDdms_device_mode.device_mode_id
*/
private Long deviceModeId;
/**
*
*/
private String machineCode;
/**
* 1 2
*/
private String faultType;
/**
* ID
*/
private Long machineId;
/**
*
*/
private Map<String, Object> params;
}

@ -0,0 +1,59 @@
package org.dromara.dms.domain.vo;
import com.alibaba.excel.annotation.ExcelProperty;
import lombok.Data;
import org.dromara.common.excel.annotation.ExcelDictFormat;
import java.math.BigDecimal;
import java.util.Date;
/**
*
*/
@Data
public class FaultTraceReportVo {
@ExcelProperty(value = "统计周期")
private String periodLabel;
private Date periodStart;
@ExcelProperty(value = "设备类型")
private String deviceType;
@ExcelProperty(value = "设备编号")
private String machineCode;
@ExcelProperty(value = "故障类型")
@ExcelDictFormat(dictType = "activity_fault_type")
private String faultType;
@ExcelProperty(value = "故障次数")
private Long faultCount;
@ExcelProperty(value = "总停机时长(小时)")
private BigDecimal totalDowntimeHours;
@ExcelProperty(value = "MTBF小时")
private BigDecimal mtbfHours;
@ExcelProperty(value = "MTTR分钟")
private BigDecimal mttrMinutes;
@ExcelProperty(value = "产量损失(件)")
private BigDecimal outputLoss;
@ExcelProperty(value = "工单延误数")
private Long delayCount;
@ExcelProperty(value = "高频故障原因")
private String topCause;
@ExcelProperty(value = "改善措施")
private String topResolution;
@ExcelProperty(value = "措施实施时间")
private Date topResolutionTime;
}

@ -0,0 +1,16 @@
package org.dromara.dms.mapper;
import com.baomidou.mybatisplus.core.metadata.IPage;
import com.baomidou.mybatisplus.extension.plugins.pagination.Page;
import org.apache.ibatis.annotations.Param;
import org.dromara.dms.domain.bo.FaultTraceReportBo;
import org.dromara.dms.domain.vo.FaultTraceReportVo;
import java.util.List;
public interface DmsReportMapper {
IPage<FaultTraceReportVo> selectFaultTracePage(Page<?> page, @Param("bo") FaultTraceReportBo bo);
List<FaultTraceReportVo> selectFaultTraceList(@Param("bo") FaultTraceReportBo bo);
}

@ -0,0 +1,17 @@
package org.dromara.dms.service;
import org.dromara.common.mybatis.core.page.PageQuery;
import org.dromara.common.mybatis.core.page.TableDataInfo;
import org.dromara.dms.domain.bo.FaultTraceReportBo;
import org.dromara.dms.domain.vo.FaultTraceReportVo;
import java.util.List;
public interface IDmsReportService {
public TableDataInfo<FaultTraceReportVo> queryFaultTrace(FaultTraceReportBo bo, PageQuery pageQuery);
public List<FaultTraceReportVo> exportFaultTrace(FaultTraceReportBo bo);
}

@ -0,0 +1,31 @@
package org.dromara.dms.service.impl;
import com.baomidou.mybatisplus.core.metadata.IPage;
import lombok.RequiredArgsConstructor;
import org.dromara.common.mybatis.core.page.PageQuery;
import org.dromara.common.mybatis.core.page.TableDataInfo;
import org.dromara.dms.domain.bo.FaultTraceReportBo;
import org.dromara.dms.domain.vo.FaultTraceReportVo;
import org.dromara.dms.mapper.DmsReportMapper;
import org.dromara.dms.service.IDmsReportService;
import org.springframework.stereotype.Service;
import java.util.List;
@RequiredArgsConstructor
@Service
public class DmsReportServiceImpl implements IDmsReportService {
private final DmsReportMapper dmsReportMapper;
@Override
public TableDataInfo<FaultTraceReportVo> queryFaultTrace(FaultTraceReportBo bo, PageQuery pageQuery) {
IPage<FaultTraceReportVo> page = dmsReportMapper.selectFaultTracePage(pageQuery.build(), bo);
return TableDataInfo.build(page);
}
@Override
public List<FaultTraceReportVo> exportFaultTrace(FaultTraceReportBo bo) {
return dmsReportMapper.selectFaultTraceList(bo);
}
}

@ -0,0 +1,414 @@
<?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.dms.mapper.DmsReportMapper">
<!--1. 产量损失output_loss_qty计算逻辑
第一步:获取故障停机时间
涉及表dms_bills_fault_instance
字段real_begin_time - 实际开始维修时间(故障开始时间)
字段real_end_time - 实际结束维修时间(故障结束时间)
- 计算停机秒数
datediff(second, fb.real_begin_time, fb.real_end_time)
第二步:获取设备标准生产节拍
涉及表关联链:
prod_base_machine_process表 - 机台与工序关联表
字段machine_id - 机台ID关联到故障的机台
字段process_id - 工序ID该机台可执行的工序
字段tenant_id - 租户ID
prod_base_process_info表 - 工序基础信息表
字段process_id - 工序ID与机台工序关联表连接
字段production_time - 生产时间(秒/件),优先使用
字段theoretical_cycle_time - 理论循环时间(秒/件),备选
- 标准秒/件计算逻辑
coalesce(
nullif(min(pi.production_time), 0), - 优先使用生产时间
nullif(min(pi.theoretical_cycle_time), 0), - 其次使用理论循环时间
60 - 默认60秒/件
) as standard_seconds_per_unit
第三步:计算产量损失
公式:停机秒数 ÷ 标准秒/件 = 损失件数
cast(case
when fb.real_begin_time is not null and fb.real_end_time is not null
and fb.real_end_time >= fb.real_begin_time
and fb.standard_seconds_per_unit is not null and fb.standard_seconds_per_unit > 0
then (datediff(second, fb.real_begin_time, fb.real_end_time) / fb.standard_seconds_per_unit)
else 0.0
end as decimal(18,2)) as output_loss_qty
举例说明:
故障停机时间2小时 = 7200秒
该机台标准节拍60秒/件
产量损失 = 7200 ÷ 60 = 120件
2. 工单延误数order_delay_count计算逻辑
第一步:确定故障时间窗口
涉及表dms_bills_fault_instance
字段machine_id - 故障机台ID
字段real_begin_time - 故障开始时间
字段real_end_time - 故障结束时间
第二步:查找受影响的生产计划
涉及表prod_plan_info - 生产计划主表
字段plan_id - 计划ID主键
字段process_id - 计划工序ID
字段plan_status - 计划状态('3'表示已完成)
字段plan_begin_time - 计划开始时间
字段plan_end_time - 计划结束时间
第三步:机台工序能力匹配
涉及表prod_base_machine_process - 机台工序关联表
字段machine_id - 机台ID必须与故障机台一致
字段process_id - 工序ID与计划工序匹配
第四步:时间窗口重叠判断
时间重叠的三种情况:
计划开始时间在故障窗口内
p.plan_begin_time between fb.real_begin_time and fb.real_end_time
计划结束时间在故障窗口内
p.plan_end_time between fb.real_begin_time and fb.real_end_time
故障时间完全包含在计划时间内
fb.real_begin_time between p.plan_begin_time and p.plan_end_time
第五步:统计延误工单数
select count(distinct p.plan_id) - 去重统计受影响的计划数
from prod_plan_info p
join prod_base_machine_process mp2 on mp2.process_id = p.process_id
where mp2.machine_id = fb.machine_id - 同一机台
and p.plan_status <> '3' - 未完成状态
and p.plan_begin_time is not null - 有明确计划时间
and p.plan_end_time is not null
and (时间重叠条件) - 时间窗口重叠
举例说明:
故障时间2025-09-16 10:00 ~ 12:00
机台EQ001发生故障
该机台可执行工序A、B、C
计划1工序A09:00-11:00 ✓延误(结束时间重叠)
计划2工序B13:00-15:00 ✗不延误(无时间重叠)
计划3工序C10:30-14:00 ✓延误(开始时间重叠)
结果:延误工单数 = 2
核心业务逻辑总结
产量损失:基于设备实际停机时间和标准生产节拍,计算理论上应该生产但因故障未能生产的产品数量
工单延误数:统计故障期间,原本安排在该设备上执行且时间有重叠的未完成生产计划数量
这两个指标反映了设备故障对生产的直接影响:产量损失体现了产能损失,工单延误数体现了计划执行的影响程度。-->
<!-- 公共聚合SQLSQL Server日期函数版本 -->
<sql id="FaultTraceAggSql">
select
g.tenant_id,
g.period_start,
g.period_label,
g.period_hours,
g.device_type,
g.machine_code,
g.fault_type,
count(1) as fault_count,
sum(g.downtime_hours) as total_downtime_hours,
sum(case when g.real_end_time is not null and g.require_end_time is not null and g.real_end_time > g.require_end_time then 1 else 0 end) as delay_count,
sum(g.output_loss_qty) as total_output_loss,
sum(g.order_delay_count) as total_order_delay_count
from (
select
fb.tenant_id as tenant_id,
fb.repair_instance_id,
fb.machine_id,
fb.machine_code,
fb.device_type,
fb.apply_time,
fb.real_begin_time,
fb.real_end_time,
fb.require_end_time,
-- 周起始
dateadd(week, datediff(week, datefromparts(year(fb.apply_time), month(fb.apply_time), 1), fb.apply_time),
datefromparts(year(fb.apply_time), month(fb.apply_time), 1)) as period_start,
cast(year(fb.apply_time) as varchar(4)) + N' 年 ' +
cast(month(fb.apply_time) as varchar(2)) + N' 月第 ' +
cast(1 + datediff(week, datefromparts(year(fb.apply_time), month(fb.apply_time), 1), fb.apply_time) as varchar(2)) + N' 周' as period_label,
datediff(hour,
dateadd(week, datediff(week, datefromparts(year(fb.apply_time), month(fb.apply_time), 1), fb.apply_time),
datefromparts(year(fb.apply_time), month(fb.apply_time), 1)),
dateadd(day, 7,
dateadd(week, datediff(week, datefromparts(year(fb.apply_time), month(fb.apply_time), 1), fb.apply_time),
datefromparts(year(fb.apply_time), month(fb.apply_time), 1)))
) as period_hours,
-- 故障类型:直接使用原始值
coalesce(af.fault_type, '') as fault_type,
cast(case
when fb.real_begin_time is not null and fb.real_end_time is not null and fb.real_end_time >= fb.real_begin_time
then datediff(second, fb.real_begin_time, fb.real_end_time) / 3600.0
else 0.0
end as decimal(18,6)) as downtime_hours,
-- 产量损失:停机秒数 / 标准秒/件
cast(case
when fb.real_begin_time is not null and fb.real_end_time is not null and fb.real_end_time >= fb.real_begin_time
and fb.standard_seconds_per_unit is not null and fb.standard_seconds_per_unit > 0
then (datediff(second, fb.real_begin_time, fb.real_end_time) / fb.standard_seconds_per_unit)
else 0.0
end as decimal(18,2)) as output_loss_qty,
-- 工单延误数:故障窗与计划窗时间重叠、同机台可执行工序、且未完成的工单数
(
select count(distinct p.plan_id)
from prod_plan_info p
join prod_base_machine_process mp2
on mp2.process_id = p.process_id
where mp2.machine_id = fb.machine_id
and p.plan_status &lt;&gt; '3'
and p.plan_begin_time is not null
and p.plan_end_time is not null
and (
(p.plan_begin_time between fb.real_begin_time and fb.real_end_time) or
(p.plan_end_time between fb.real_begin_time and fb.real_end_time) or
(fb.real_begin_time between p.plan_begin_time and p.plan_end_time)
)
) as order_delay_count
from (
select
fi.tenant_id as tenant_id,
fi.repair_instance_id,
fi.machine_id,
fi.apply_time,
fi.real_begin_time,
fi.real_end_time,
fi.require_end_time,
m.machine_code,
dm.device_mode_name as device_type,
std.standard_seconds_per_unit
from dms_bills_fault_instance fi
join prod_base_machine_info m
on m.machine_id = fi.machine_id
left join dms_device_mode dm
on dm.device_mode_id = m.device_mode_id
left join (
select
mp.tenant_id,
mp.machine_id,
coalesce(
nullif(min(pi.production_time), 0),
nullif(min(pi.theoretical_cycle_time), 0),
60
) as standard_seconds_per_unit
from prod_base_machine_process mp
join prod_base_process_info pi
on pi.process_id = mp.process_id
where pi.production_time > 0 or pi.theoretical_cycle_time > 0
group by mp.tenant_id, mp.machine_id
) std
on std.machine_id = fi.machine_id
and std.tenant_id = fi.tenant_id
where fi.active_flag = '1'
and fi.apply_time is not null
<if test="bo.startDate != null">
and fi.apply_time &gt;= #{bo.startDate}
</if>
<if test="bo.endDate != null">
and fi.apply_time &lt; #{bo.endDate}
</if>
<if test="bo.machineId != null">
and fi.machine_id = #{bo.machineId}
</if>
<if test="bo.machineCode != null and bo.machineCode != ''">
and m.machine_code like concat('%', #{bo.machineCode}, '%')
</if>
<if test="bo.deviceModeId != null">
and m.device_mode_id = #{bo.deviceModeId}
</if>
) fb
left join (
select repair_instance_id, fault_type
from (
select repair_instance_id, fault_type, start_time,
row_number() over(partition by repair_instance_id order by start_time asc, instance_activity_id asc) as rn
from dms_fault_instance_activity
) t
where t.rn = 1
) af
on af.repair_instance_id = fb.repair_instance_id
<if test="bo.faultType != null and bo.faultType != ''">
where coalesce(af.fault_type, '') = #{bo.faultType}
</if>
) g
group by
g.tenant_id,
g.period_start, g.period_label, g.period_hours,
g.device_type, g.machine_code, g.fault_type
</sql>
<!-- 抽取完整查询为公共片段,供分页与导出共用 -->
<sql id="FaultTraceMain">
with agg as (
<include refid="FaultTraceAggSql"/>
),
top_cause as (
select period_start, device_type, machine_code, fault_type, top_cause, tenant_id
from (
select
fi.tenant_id as tenant_id,
dateadd(week, datediff(week, datefromparts(year(fi.apply_time), month(fi.apply_time), 1), fi.apply_time),
datefromparts(year(fi.apply_time), month(fi.apply_time), 1)) as period_start,
coalesce(dm.device_mode_name, N'') as device_type,
m.machine_code,
coalesce(af.fault_type, '') as fault_type,
a.fault_description as top_cause,
count(*) as cnt,
row_number() over(
partition by
fi.tenant_id,
dateadd(week, datediff(week, datefromparts(year(fi.apply_time), month(fi.apply_time), 1), fi.apply_time),
datefromparts(year(fi.apply_time), month(fi.apply_time), 1)),
coalesce(dm.device_mode_name, N''),
m.machine_code,
coalesce(af.fault_type, '')
order by count(*) desc, a.fault_description
) as rn
from dms_fault_instance_activity a
join dms_bills_fault_instance fi
on fi.repair_instance_id = a.repair_instance_id
join prod_base_machine_info m
on m.machine_id = fi.machine_id
left join dms_device_mode dm
on dm.device_mode_id = m.device_mode_id
left join (
select repair_instance_id, fault_type
from (
select repair_instance_id, fault_type, start_time,
row_number() over(partition by repair_instance_id order by start_time asc, instance_activity_id asc) as rn
from dms_fault_instance_activity
) t2
where t2.rn = 1
) af
on af.repair_instance_id = fi.repair_instance_id
where fi.active_flag = '1'
and fi.apply_time is not null
and a.fault_description is not null and ltrim(rtrim(a.fault_description)) &lt;&gt; ''
<if test="bo.startDate != null">
and fi.apply_time &gt;= #{bo.startDate}
</if>
<if test="bo.endDate != null">
and fi.apply_time &lt; #{bo.endDate}
</if>
<if test="bo.machineId != null">
and fi.machine_id = #{bo.machineId}
</if>
<if test="bo.machineCode != null and bo.machineCode != ''">
and m.machine_code like concat('%', #{bo.machineCode}, '%')
</if>
<if test="bo.deviceModeId != null">
and m.device_mode_id = #{bo.deviceModeId}
</if>
<if test="bo.faultType != null and bo.faultType != ''">
and coalesce(af.fault_type, '') = #{bo.faultType}
</if>
group by
fi.tenant_id,
dateadd(week, datediff(week, datefromparts(year(fi.apply_time), month(fi.apply_time), 1), fi.apply_time),
datefromparts(year(fi.apply_time), month(fi.apply_time), 1)),
coalesce(dm.device_mode_name, N''),
m.machine_code,
coalesce(af.fault_type, ''),
a.fault_description
) c
where c.rn = 1
),
top_resolution as (
select *
from (
select
fi.tenant_id as tenant_id,
dateadd(week, datediff(week, datefromparts(year(fi.apply_time), month(fi.apply_time), 1), fi.apply_time),
datefromparts(year(fi.apply_time), month(fi.apply_time), 1)) as period_start,
coalesce(dm.device_mode_name, N'') as device_type,
m.machine_code,
coalesce(af.fault_type, '') as fault_type,
a2.process_handle_resolution as top_resolution,
a2.handle_time as top_resolution_time,
row_number() over(
partition by
fi.tenant_id,
dateadd(week, datediff(week, datefromparts(year(fi.apply_time), month(fi.apply_time), 1), fi.apply_time),
datefromparts(year(fi.apply_time), month(fi.apply_time), 1)),
coalesce(dm.device_mode_name, N''),
m.machine_code,
coalesce(af.fault_type, '')
order by a2.handle_time desc, a2.instance_activity_id desc
) as rn
from dms_fault_instance_activity a2
join dms_bills_fault_instance fi
on fi.repair_instance_id = a2.repair_instance_id
join prod_base_machine_info m
on m.machine_id = fi.machine_id
left join dms_device_mode dm
on dm.device_mode_id = m.device_mode_id
left join (
select repair_instance_id, fault_type
from (
select repair_instance_id, fault_type, start_time,
row_number() over(partition by repair_instance_id order by start_time asc, instance_activity_id asc) as rn
from dms_fault_instance_activity
) t3
where t3.rn = 1
) af
on af.repair_instance_id = fi.repair_instance_id
where fi.active_flag = '1'
and fi.apply_time is not null
and a2.process_handle_resolution is not null and ltrim(rtrim(a2.process_handle_resolution)) &lt;&gt; ''
<if test="bo.startDate != null">
and fi.apply_time &gt;= #{bo.startDate}
</if>
<if test="bo.endDate != null">
and fi.apply_time &lt; #{bo.endDate}
</if>
<if test="bo.machineId != null">
and fi.machine_id = #{bo.machineId}
</if>
<if test="bo.machineCode != null and bo.machineCode != ''">
and m.machine_code like concat('%', #{bo.machineCode}, '%')
</if>
<if test="bo.deviceModeId != null">
and m.device_mode_id = #{bo.deviceModeId}
</if>
<if test="bo.faultType != null and bo.faultType != ''">
and coalesce(af.fault_type, '') = #{bo.faultType}
</if>
) z where z.rn = 1
)
select
a.period_label,
a.period_start,
a.device_type,
a.machine_code,
a.fault_type,
a.fault_count,
cast(a.total_downtime_hours as decimal(18,2)) as total_downtime_hours,
cast(a.period_hours / nullif(a.fault_count, 0) as decimal(18,2)) as mtbf_hours,
cast(a.total_downtime_hours * 60.0 / nullif(a.fault_count, 0) as decimal(18,2)) as mttr_minutes,
cast(a.total_output_loss as decimal(18,2)) as output_loss,
a.total_order_delay_count as delay_count,
coalesce(ca.top_cause, N'') as top_cause,
coalesce(tr.top_resolution, N'') as top_resolution,
tr.top_resolution_time
from agg a
left join top_cause ca
on ca.period_start = a.period_start
and ca.device_type = a.device_type
and ca.machine_code = a.machine_code
and ca.fault_type = a.fault_type
left join top_resolution tr
on tr.period_start = a.period_start
and tr.device_type = a.device_type
and tr.machine_code = a.machine_code
and tr.fault_type = a.fault_type
order by a.period_start desc, a.machine_code, a.fault_type
</sql>
<!-- 分页查询 -->
<select id="selectFaultTracePage" resultType="org.dromara.dms.domain.vo.FaultTraceReportVo">
<include refid="FaultTraceMain"/>
</select>
<!-- 导出用(不分页) -->
<select id="selectFaultTraceList" resultType="org.dromara.dms.domain.vo.FaultTraceReportVo">
<include refid="FaultTraceMain"/>
</select>
</mapper>

@ -0,0 +1,207 @@
package org.dromara.mes.utils;
import com.alibaba.excel.EasyExcel;
import com.alibaba.excel.write.metadata.WriteSheet;
import com.alibaba.excel.write.metadata.WriteTable;
import com.alibaba.excel.write.metadata.style.WriteCellStyle;
import com.alibaba.excel.write.metadata.style.WriteFont;
import com.alibaba.excel.write.style.HorizontalCellStyleStrategy;
import org.apache.poi.ss.usermodel.HorizontalAlignment;
import org.apache.poi.ss.usermodel.VerticalAlignment;
import org.dromara.mes.domain.vo.ProdProductPlanDetailStatisticsVo;
import jakarta.servlet.http.HttpServletResponse;
import java.io.IOException;
import java.math.BigDecimal;
import java.net.URLEncoder;
import java.nio.charset.StandardCharsets;
import java.util.*;
/**
* Excel
*
* @author Yinq
* @date 2025-03-05
*/
public class DynamicExcelExportUtil {
/**
* Excel
*
* @param response HTTP
* @param fileName
* @param dataList
* @param shiftNames
* @throws IOException IO
*/
public static void exportMachineShiftStatistics(HttpServletResponse response, String fileName,
List<ProdProductPlanDetailStatisticsVo> dataList,
List<String> shiftNames) throws IOException {
// 设置响应头
response.setContentType("application/vnd.openxmlformats-officedocument.spreadsheetml.sheet");
response.setCharacterEncoding("utf-8");
String encodedFileName = URLEncoder.encode(fileName, StandardCharsets.UTF_8).replaceAll("\\+", "%20");
response.setHeader("Content-disposition", "attachment;filename*=utf-8''" + encodedFileName + ".xlsx");
// 构建动态表头
List<List<String>> headers = buildDynamicHeaders(shiftNames);
// 构建数据行
List<List<Object>> dataRows = buildDataRows(dataList, shiftNames);
// 创建样式策略
HorizontalCellStyleStrategy styleStrategy = createStyleStrategy();
// 写入Excel
EasyExcel.write(response.getOutputStream())
.head(headers)
.registerWriteHandler(styleStrategy)
.sheet("机台班次统计")
.doWrite(dataRows);
}
/**
*
*
* @param shiftNames
* @return
*/
private static List<List<String>> buildDynamicHeaders(List<String> shiftNames) {
List<List<String>> headers = new ArrayList<>();
// 固定列:序号、机台
headers.add(Arrays.asList("序号"));
headers.add(Arrays.asList("机台"));
// 动态班次列
if (shiftNames != null && !shiftNames.isEmpty()) {
for (String shiftName : shiftNames) {
headers.add(Arrays.asList(shiftName));
}
} else {
// 默认早、夜班次
headers.add(Arrays.asList("早"));
headers.add(Arrays.asList("夜"));
}
// 固定列:合计、单位
headers.add(Arrays.asList("合计"));
headers.add(Arrays.asList("单位"));
return headers;
}
/**
*
*
* @param dataList
* @param shiftNames
* @return
*/
private static List<List<Object>> buildDataRows(List<ProdProductPlanDetailStatisticsVo> dataList,
List<String> shiftNames) {
List<List<Object>> dataRows = new ArrayList<>();
// 数据行
for (ProdProductPlanDetailStatisticsVo vo : dataList) {
List<Object> row = new ArrayList<>();
// 序号
row.add(vo.getRowNumber());
// 机台
row.add(vo.getMachineCode());
// 动态班次数据
if (shiftNames != null && !shiftNames.isEmpty()) {
for (String shiftName : shiftNames) {
BigDecimal amount = vo.getShiftAmountMap() != null ?
vo.getShiftAmountMap().getOrDefault(shiftName, BigDecimal.ZERO) : BigDecimal.ZERO;
row.add(amount);
}
} else {
// 默认早、夜班次
row.add(vo.getMorningShiftAmount() != null ? vo.getMorningShiftAmount() : BigDecimal.ZERO);
row.add(vo.getNightShiftAmount() != null ? vo.getNightShiftAmount() : BigDecimal.ZERO);
}
// 合计
row.add(vo.getTotalAmount() != null ? vo.getTotalAmount() : BigDecimal.ZERO);
// 单位
row.add(vo.getUnitName() != null ? vo.getUnitName() : "");
dataRows.add(row);
}
// 合计行
if (!dataList.isEmpty()) {
List<Object> totalRow = new ArrayList<>();
totalRow.add(""); // 序号列空白
totalRow.add("合计"); // 机台列显示"合计"
// 计算各班次合计
if (shiftNames != null && !shiftNames.isEmpty()) {
for (String shiftName : shiftNames) {
BigDecimal shiftTotal = dataList.stream()
.filter(vo -> vo.getShiftAmountMap() != null)
.map(vo -> vo.getShiftAmountMap().getOrDefault(shiftName, BigDecimal.ZERO))
.reduce(BigDecimal.ZERO, BigDecimal::add);
totalRow.add(shiftTotal);
}
} else {
// 默认早、夜班次合计
BigDecimal morningTotal = dataList.stream()
.map(vo -> vo.getMorningShiftAmount() != null ? vo.getMorningShiftAmount() : BigDecimal.ZERO)
.reduce(BigDecimal.ZERO, BigDecimal::add);
BigDecimal nightTotal = dataList.stream()
.map(vo -> vo.getNightShiftAmount() != null ? vo.getNightShiftAmount() : BigDecimal.ZERO)
.reduce(BigDecimal.ZERO, BigDecimal::add);
totalRow.add(morningTotal);
totalRow.add(nightTotal);
}
// 总合计
BigDecimal grandTotal = dataList.stream()
.map(vo -> vo.getTotalAmount() != null ? vo.getTotalAmount() : BigDecimal.ZERO)
.reduce(BigDecimal.ZERO, BigDecimal::add);
totalRow.add(grandTotal);
// 单位列空白
totalRow.add("");
dataRows.add(totalRow);
}
return dataRows;
}
/**
*
*
* @return
*/
private static HorizontalCellStyleStrategy createStyleStrategy() {
// 表头样式
WriteCellStyle headWriteCellStyle = new WriteCellStyle();
headWriteCellStyle.setHorizontalAlignment(HorizontalAlignment.CENTER);
headWriteCellStyle.setVerticalAlignment(VerticalAlignment.CENTER);
WriteFont headWriteFont = new WriteFont();
headWriteFont.setFontName("Arial");
headWriteFont.setFontHeightInPoints((short) 12);
headWriteFont.setBold(true);
headWriteCellStyle.setWriteFont(headWriteFont);
// 内容样式
WriteCellStyle contentWriteCellStyle = new WriteCellStyle();
contentWriteCellStyle.setHorizontalAlignment(HorizontalAlignment.CENTER);
contentWriteCellStyle.setVerticalAlignment(VerticalAlignment.CENTER);
WriteFont contentWriteFont = new WriteFont();
contentWriteFont.setFontName("Arial");
contentWriteFont.setFontHeightInPoints((short) 11);
contentWriteCellStyle.setWriteFont(contentWriteFont);
return new HorizontalCellStyleStrategy(headWriteCellStyle, contentWriteCellStyle);
}
}
Loading…
Cancel
Save