|
|
|
@ -68,7 +68,7 @@ public class Board4ProductionTotalVo {
|
|
|
|
/** 年累计产量(去年数据,来源BASE_ORDERINFO) */
|
|
|
|
/** 年累计产量(去年数据,来源BASE_ORDERINFO) */
|
|
|
|
private Long yearTotal;
|
|
|
|
private Long yearTotal;
|
|
|
|
|
|
|
|
|
|
|
|
/** 月累计产量(当月数据,来源BASE_ORDERINFO) */
|
|
|
|
/** 月累计产量(当月数据,来源BASE_DEVICE_PARAM_VAL,按设备取当月最新“机台状态-实际产出数量”汇总) */
|
|
|
|
private Long monthTotal;
|
|
|
|
private Long monthTotal;
|
|
|
|
|
|
|
|
|
|
|
|
/** 日累计产量(当天数据,来源BASE_DEVICE_PARAM_VAL,PARAM_NAME='机台状态-实际产出数量') */
|
|
|
|
/** 日累计产量(当天数据,来源BASE_DEVICE_PARAM_VAL,PARAM_NAME='机台状态-实际产出数量') */
|
|
|
|
@ -227,7 +227,7 @@ public class Board4DeviceProductionVo {
|
|
|
|
### 4.1 接口数据源映射表
|
|
|
|
### 4.1 接口数据源映射表
|
|
|
|
|
|
|
|
|
|
|
|
| 接口 | 数据源表 | 业务逻辑 |
|
|
|
|
| 接口 | 数据源表 | 业务逻辑 |
|
|
|
|
| productionTotal | BASE_ORDERINFO, BASE_DEVICE_PARAM_VAL | 年累计=去年SUM(COMPLETE_AMOUNT),月累计=当月SUM(COMPLETE_AMOUNT),日累计=当天PARAM_NAME='机台状态-实际产出数量'最新值汇总(按设备取最新一条) |
|
|
|
|
| productionTotal | BASE_ORDERINFO, BASE_DEVICE_PARAM_VAL | 年累计=去年SUM(COMPLETE_AMOUNT);月累计=当月每台设备最新PARAM_NAME='机台状态-实际产出数量'汇总;日累计=当天每台设备最新PARAM_NAME='机台状态-实际产出数量'汇总 |
|
|
|
|
| orderStatistics | BASE_ORDERINFO | 当天SUM(ORDER_AMOUNT)和SUM(COMPLETE_AMOUNT),差异=计划-完成,完成率=完成/计划 |
|
|
|
|
| orderStatistics | BASE_ORDERINFO | 当天SUM(ORDER_AMOUNT)和SUM(COMPLETE_AMOUNT),差异=计划-完成,完成率=完成/计划 |
|
|
|
|
| orderProgressList | BASE_ORDERINFO | 当天工单列表,进度=完成/计划百分比并带% |
|
|
|
|
| orderProgressList | BASE_ORDERINFO | 当天工单列表,进度=完成/计划百分比并带% |
|
|
|
|
| deviceStatus | BASE_DEVICELEDGER, DMS_BILLS_FAULT_INSTANCE | IS_FLAG=0有效设备,按DEVICE_STATUS分组统计+总维修次数 |
|
|
|
|
| deviceStatus | BASE_DEVICELEDGER, DMS_BILLS_FAULT_INSTANCE | IS_FLAG=0有效设备,按DEVICE_STATUS分组统计+总维修次数 |
|
|
|
|
@ -259,7 +259,27 @@ WHERE RN = 1 -- 仅保留最新一条
|
|
|
|
- **窗口函数作用**:`ROW_NUMBER() OVER (PARTITION BY DEVICE_CODE ORDER BY COLLECT_TIME DESC)` 按设备分组,按采集时间倒序排列,取 RN=1 即每台设备当天最新的一条记录
|
|
|
|
- **窗口函数作用**:`ROW_NUMBER() OVER (PARTITION BY DEVICE_CODE ORDER BY COLLECT_TIME DESC)` 按设备分组,按采集时间倒序排列,取 RN=1 即每台设备当天最新的一条记录
|
|
|
|
- **汇总逻辑**:将所有设备的最新实际产出数量求和,得到日累计产量
|
|
|
|
- **汇总逻辑**:将所有设备的最新实际产出数量求和,得到日累计产量
|
|
|
|
|
|
|
|
|
|
|
|
#### 4.2.2 维修分析(按设备聚合)
|
|
|
|
#### 4.2.2 月累计产量(BASE_DEVICE_PARAM_VAL)
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
```sql
|
|
|
|
|
|
|
|
SELECT NVL(SUM(TO_NUMBER(PARAM_VALUE)), 0) -- 汇总当月实际产出数量
|
|
|
|
|
|
|
|
FROM (
|
|
|
|
|
|
|
|
SELECT DEVICE_CODE, PARAM_VALUE,
|
|
|
|
|
|
|
|
ROW_NUMBER() OVER (PARTITION BY DEVICE_CODE ORDER BY COLLECT_TIME DESC) AS RN -- 每台设备取最新记录
|
|
|
|
|
|
|
|
FROM BASE_DEVICE_PARAM_VAL
|
|
|
|
|
|
|
|
WHERE PARAM_NAME = '机台状态-实际产出数量' -- 固定参数名称
|
|
|
|
|
|
|
|
AND COLLECT_TIME >= TRUNC(SYSDATE, 'MM') AND COLLECT_TIME < ADD_MONTHS(TRUNC(SYSDATE, 'MM'), 1) -- 当月数据
|
|
|
|
|
|
|
|
)
|
|
|
|
|
|
|
|
WHERE RN = 1 -- 仅保留最新一条
|
|
|
|
|
|
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
**业务逻辑说明**:
|
|
|
|
|
|
|
|
- 与日累计一致的取数口径,但时间范围是本自然月(当月1日00:00:00至下月1日00:00:00)
|
|
|
|
|
|
|
|
- 按设备取当月最新一条"机台状态-实际产出数量",再汇总得到月累计产量
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
> 原先的月累计(工单完成量 SUM(COMPLETE_AMOUNT))已替换为上述设备参数口径,旧逻辑在 Mapper XML 中以注释保留。
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
#### 4.2.3 维修分析(按设备聚合)
|
|
|
|
|
|
|
|
|
|
|
|
```sql
|
|
|
|
```sql
|
|
|
|
SELECT d.DEVICE_NAME AS deviceName, -- 设备名称
|
|
|
|
SELECT d.DEVICE_NAME AS deviceName, -- 设备名称
|
|
|
|
@ -272,7 +292,7 @@ GROUP BY d.OBJ_ID, d.DEVICE_NAME -- 按设备聚合
|
|
|
|
ORDER BY repairCount DESC -- 按次数降序
|
|
|
|
ORDER BY repairCount DESC -- 按次数降序
|
|
|
|
```
|
|
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
#### 4.2.3 设备产量列表
|
|
|
|
#### 4.2.4 设备产量列表
|
|
|
|
|
|
|
|
|
|
|
|
```sql
|
|
|
|
```sql
|
|
|
|
SELECT d.DEVICE_NAME AS deviceName, -- 设备名称
|
|
|
|
SELECT d.DEVICE_NAME AS deviceName, -- 设备名称
|
|
|
|
@ -285,18 +305,18 @@ LEFT JOIN (
|
|
|
|
ROW_NUMBER() OVER (PARTITION BY DEVICE_CODE ORDER BY COLLECT_TIME DESC) AS RN -- 每台设备最新记录
|
|
|
|
ROW_NUMBER() OVER (PARTITION BY DEVICE_CODE ORDER BY COLLECT_TIME DESC) AS RN -- 每台设备最新记录
|
|
|
|
FROM BASE_DEVICE_PARAM_VAL
|
|
|
|
FROM BASE_DEVICE_PARAM_VAL
|
|
|
|
WHERE PARAM_NAME = '机台状态-实际产出数量' -- 固定参数名称
|
|
|
|
WHERE PARAM_NAME = '机台状态-实际产出数量' -- 固定参数名称
|
|
|
|
AND TO_CHAR(COLLECT_TIME, 'YYYY-MM-DD') = TO_CHAR(SYSDATE, 'YYYY-MM-DD') -- 当天数据
|
|
|
|
AND COLLECT_TIME >= TRUNC(SYSDATE) AND COLLECT_TIME < TRUNC(SYSDATE) + 1 -- 当天数据
|
|
|
|
)
|
|
|
|
)
|
|
|
|
WHERE RN = 1 -- 仅保留最新一条
|
|
|
|
WHERE RN = 1 -- 仅保留最新一条
|
|
|
|
) p ON d.DEVICE_CODE = p.DEVICE_CODE -- 关联设备编码
|
|
|
|
) p ON d.DEVICE_CODE = p.DEVICE_CODE -- 关联设备编码
|
|
|
|
WHERE d.IS_FLAG = 0 AND d.DEVICE_TYPE = '1' -- 仅生产设备
|
|
|
|
WHERE d.IS_FLAG = 1 -- 有效设备
|
|
|
|
ORDER BY production DESC -- 按产量降序
|
|
|
|
ORDER BY production DESC -- 按产量降序
|
|
|
|
```
|
|
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
**业务逻辑说明**:
|
|
|
|
**业务逻辑说明**:
|
|
|
|
- **关联查询**:将设备台账表(BASE_DEVICELEDGER)与设备工艺参数表(BASE_DEVICE_PARAM_VAL)通过 DEVICE_CODE 关联
|
|
|
|
- **关联查询**:将设备台账表(BASE_DEVICELEDGER)与设备工艺参数表(BASE_DEVICE_PARAM_VAL)通过 DEVICE_CODE 关联
|
|
|
|
- **筛选条件**:`PARAM_NAME = '机台状态-实际产出数量'` 获取实际产出数量参数
|
|
|
|
- **筛选条件**:`PARAM_NAME = '机台状态-实际产出数量'` 获取实际产出数量参数
|
|
|
|
- **设备过滤**:`IS_FLAG = 0`(NUMBER类型,有效设备)且 `DEVICE_TYPE = '1'`(生产设备)
|
|
|
|
- **设备过滤**:`IS_FLAG = 1`(有效设备)
|
|
|
|
- **排序逻辑**:按产量降序排列,产量高的设备排在前面
|
|
|
|
- **排序逻辑**:按产量降序排列,产量高的设备排在前面
|
|
|
|
|
|
|
|
|
|
|
|
### 4.3 服务层返回规则补充
|
|
|
|
### 4.3 服务层返回规则补充
|
|
|
|
@ -702,18 +722,38 @@ public class Board5ProductionTopVo {
|
|
|
|
|
|
|
|
|
|
|
|
| 接口 | 数据源表 | 业务逻辑 |
|
|
|
|
| 接口 | 数据源表 | 业务逻辑 |
|
|
|
|
|------|----------|----------|
|
|
|
|
|------|----------|----------|
|
|
|
|
| orderWorkStatistics | BASE_ORDERINFO | 统计工单总数、已完成(EXECUTION_STATUS='COMPLETED')、停机(EXECUTION_STATUS='PAUSED') |
|
|
|
|
| orderWorkStatistics | DMS_BILLS_FAULT_INSTANCE, DMS_BILLS_MAINT_INSTANCE, DMS_BILLS_INSPECT_INSTANCE | 工单总数=维修+保养+巡检;已完成=维修完成(BILLS_STATUS='2')+保养完成(MAINT_STATUS='3')+巡检完成(INSPECT_STATUS='3');停机=维修中(BILLS_STATUS='1') |
|
|
|
|
| repairTimeStatistics | DMS_BILLS_FAULT_INSTANCE | 平均响应时间=(REAL_BEGIN_TIME-APPLY_TIME),平均维修时间=(REAL_END_TIME-REAL_BEGIN_TIME) |
|
|
|
|
| repairTimeStatistics | DMS_BILLS_FAULT_INSTANCE | 平均响应时间=(REAL_BEGIN_TIME-APPLY_TIME)*24*60分钟;平均维修时间=(REAL_END_TIME-REAL_BEGIN_TIME)*24小时;仅统计BILLS_STATUS='2' |
|
|
|
|
| maintStatistics | DMS_PLAN_MAINT | 按MAINT_STATUS分组统计:1=待保养,2=保养中,3=已完成,4=待验证 |
|
|
|
|
| maintStatistics | DMS_BILLS_MAINT_INSTANCE | 按MAINT_STATUS分组统计:1=待保养,2=保养中,3=已完成,4=待验证(无此数据返回0) |
|
|
|
|
| inspectStatistics | DMS_PLAN_INSPECT, DMS_BILLS_INSPECT_INSTANCE | 应检设备=SUM(DEVICE_AMOUNT),已检=INSPECT_STATUS='2'的数量 |
|
|
|
|
| inspectStatistics | DMS_BILLS_INSPECT_INSTANCE | 应检设备=COUNT(DISTINCT PLAN_INSPECT_ID)*18;已检设备=INSPECT_STATUS='3'的数量 |
|
|
|
|
| deviceStatusDistribution | BASE_DEVICELEDGER | 按DEVICE_STATUS和DEVICE_TYPE分组统计 |
|
|
|
|
| deviceStatusDistribution | BASE_DEVICELEDGER | 按DEVICE_STATUS和DEVICE_TYPE分组统计,WHERE IS_FLAG=1 |
|
|
|
|
| faultSourceDistribution | DMS_BILLS_FAULT_INSTANCE | 按FAULT_SOURCE_TYPE分组:1=维护故障,2/3=运行故障,9=自然故障 |
|
|
|
|
| faultSourceDistribution | DMS_BILLS_FAULT_INSTANCE | 按FAULT_SOURCE_TYPE分组:1=维护故障,2/3=运行故障,9=自然故障;WHERE IS_FLAG='1' |
|
|
|
|
| faultTrendList | DMS_RECORD_ALARM_INFO | 近30天每日告警数量,按ALARM_BEGIN_TIME日期分组 |
|
|
|
|
| faultTrendList | DMS_RECORD_ALARM_INFO | 近30天每日告警数量,按ALARM_BEGIN_TIME日期分组 |
|
|
|
|
| productionTop5 | BASE_DEVICE_PARAM_VAL, BASE_DEVICELEDGER | 各设备当天PARAM_NAME='机台状态-实际产出数量'最新值,取TOP5 |
|
|
|
|
| productionTop5 | BASE_DEVICE_PARAM_VAL, BASE_DEVICELEDGER | 各设备当天PARAM_NAME='机台状态-实际产出数量'最新值,取TOP5 |
|
|
|
|
|
|
|
|
|
|
|
|
### 4.2 关键SQL说明
|
|
|
|
### 4.2 关键SQL说明
|
|
|
|
|
|
|
|
|
|
|
|
#### 4.2.1 维修时间统计
|
|
|
|
#### 4.2.1 工单统计
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
```sql
|
|
|
|
|
|
|
|
SELECT
|
|
|
|
|
|
|
|
(SELECT COUNT(*) FROM DMS_BILLS_FAULT_INSTANCE WHERE IS_FLAG = '1') +
|
|
|
|
|
|
|
|
(SELECT COUNT(*) FROM DMS_BILLS_MAINT_INSTANCE) +
|
|
|
|
|
|
|
|
(SELECT COUNT(*) FROM DMS_BILLS_INSPECT_INSTANCE WHERE IS_FLAG = '1') AS TOTAL_COUNT,
|
|
|
|
|
|
|
|
(SELECT COUNT(*) FROM DMS_BILLS_FAULT_INSTANCE WHERE IS_FLAG = '1' AND BILLS_STATUS = '2') +
|
|
|
|
|
|
|
|
(SELECT COUNT(*) FROM DMS_BILLS_MAINT_INSTANCE WHERE MAINT_STATUS = '3') +
|
|
|
|
|
|
|
|
(SELECT COUNT(*) FROM DMS_BILLS_INSPECT_INSTANCE WHERE IS_FLAG = '1' AND INSPECT_STATUS = '3') AS COMPLETE_COUNT,
|
|
|
|
|
|
|
|
(SELECT COUNT(*) FROM DMS_BILLS_FAULT_INSTANCE WHERE IS_FLAG = '1' AND BILLS_STATUS = '1') AS STOP_COUNT
|
|
|
|
|
|
|
|
FROM DUAL
|
|
|
|
|
|
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
**业务逻辑说明**:
|
|
|
|
|
|
|
|
- **工单总数** = 维修工单数 + 保养工单数 + 巡检工单数
|
|
|
|
|
|
|
|
- **已完成数** = 维修完成(BILLS_STATUS='2') + 保养完成(MAINT_STATUS='3') + 巡检完成(INSPECT_STATUS='3')
|
|
|
|
|
|
|
|
- **停机工单数** = 维修中(BILLS_STATUS='1'),即设备正在维修无法生产的工单数
|
|
|
|
|
|
|
|
- **数据范围**:全量历史数据,无时间限制
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
#### 4.2.2 维修时间统计
|
|
|
|
|
|
|
|
|
|
|
|
```sql
|
|
|
|
```sql
|
|
|
|
SELECT ROUND(NVL(AVG((REAL_BEGIN_TIME - APPLY_TIME) * 24 * 60), 0), 2) AS AVG_RESPONSE_TIME,
|
|
|
|
SELECT ROUND(NVL(AVG((REAL_BEGIN_TIME - APPLY_TIME) * 24 * 60), 0), 2) AS AVG_RESPONSE_TIME,
|
|
|
|
@ -721,14 +761,64 @@ SELECT ROUND(NVL(AVG((REAL_BEGIN_TIME - APPLY_TIME) * 24 * 60), 0), 2) AS AVG_RE
|
|
|
|
FROM DMS_BILLS_FAULT_INSTANCE
|
|
|
|
FROM DMS_BILLS_FAULT_INSTANCE
|
|
|
|
WHERE IS_FLAG = '1'
|
|
|
|
WHERE IS_FLAG = '1'
|
|
|
|
AND REAL_BEGIN_TIME IS NOT NULL
|
|
|
|
AND REAL_BEGIN_TIME IS NOT NULL
|
|
|
|
|
|
|
|
AND REAL_END_TIME IS NOT NULL
|
|
|
|
|
|
|
|
AND BILLS_STATUS = '2'
|
|
|
|
AND APPLY_TIME IS NOT NULL
|
|
|
|
AND APPLY_TIME IS NOT NULL
|
|
|
|
```
|
|
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
**业务逻辑说明**:
|
|
|
|
**业务逻辑说明**:
|
|
|
|
- 平均响应时间 = (实际开始时间 - 申请时间) × 24 × 60,单位:分钟
|
|
|
|
- **平均响应时间** = (实际开始时间 - 申请时间) × 24 × 60,单位:分钟
|
|
|
|
- 平均维修时间 = (实际结束时间 - 实际开始时间) × 24,单位:小时
|
|
|
|
- **平均维修时间** = (实际结束时间 - 实际开始时间) × 24,单位:小时
|
|
|
|
|
|
|
|
- **仅统计已完成工单**:`BILLS_STATUS = '2'`,确保时间数据完整
|
|
|
|
|
|
|
|
|
|
|
|
#### 4.2.2 故障数量曲线(使用DMS_RECORD_ALARM_INFO)
|
|
|
|
#### 4.2.3 保养执行情况统计
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
```sql
|
|
|
|
|
|
|
|
SELECT COUNT(*) AS PLAN_COUNT,
|
|
|
|
|
|
|
|
SUM(CASE WHEN MAINT_STATUS = '3' THEN 1 ELSE 0 END) AS COMPLETE_COUNT,
|
|
|
|
|
|
|
|
SUM(CASE WHEN MAINT_STATUS = '1' THEN 1 ELSE 0 END) AS WAITING_COUNT,
|
|
|
|
|
|
|
|
SUM(CASE WHEN MAINT_STATUS = '2' THEN 1 ELSE 0 END) AS DOING_COUNT,
|
|
|
|
|
|
|
|
0 AS VERIFY_COUNT
|
|
|
|
|
|
|
|
FROM DMS_BILLS_MAINT_INSTANCE
|
|
|
|
|
|
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
**业务逻辑说明**:
|
|
|
|
|
|
|
|
- **数据来源**:`DMS_BILLS_MAINT_INSTANCE` 保养工单表(非计划表)
|
|
|
|
|
|
|
|
- **状态映射**:1=待保养,2=保养中,3=已完成
|
|
|
|
|
|
|
|
- **待验证数量**:工单表中无 MAINT_STATUS=4 状态,固定返回 0
|
|
|
|
|
|
|
|
- **数据范围**:全量历史数据,该表无 IS_FLAG 字段
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
#### 4.2.4 巡检执行情况统计
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
```sql
|
|
|
|
|
|
|
|
SELECT (SELECT COUNT(DISTINCT PLAN_INSPECT_ID) * 18 FROM DMS_BILLS_INSPECT_INSTANCE WHERE IS_FLAG = '1') AS DEVICE_COUNT,
|
|
|
|
|
|
|
|
(SELECT COUNT(*) FROM DMS_BILLS_INSPECT_INSTANCE WHERE IS_FLAG = '1' AND INSPECT_STATUS = '3') AS COMPLETE_COUNT
|
|
|
|
|
|
|
|
FROM DUAL
|
|
|
|
|
|
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
**业务逻辑说明**:
|
|
|
|
|
|
|
|
- **应检设备数** = 不同巡检计划数 × 18(每计划覆盖18台设备)
|
|
|
|
|
|
|
|
- **已检设备数** = 已完成的巡检工单数(`INSPECT_STATUS = '3'`)
|
|
|
|
|
|
|
|
- **数据来源**:`DMS_BILLS_INSPECT_INSTANCE` 巡检工单表
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
#### 4.2.5 设备状态分布
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
```sql
|
|
|
|
|
|
|
|
SELECT COUNT(*) AS TOTAL_COUNT,
|
|
|
|
|
|
|
|
SUM(CASE WHEN DEVICE_STATUS = 0 THEN 1 ELSE 0 END) AS NORMAL_COUNT,
|
|
|
|
|
|
|
|
SUM(CASE WHEN DEVICE_STATUS = 1 THEN 1 ELSE 0 END) AS ABNORMAL_COUNT,
|
|
|
|
|
|
|
|
SUM(CASE WHEN DEVICE_STATUS = 2 THEN 1 ELSE 0 END) AS SCRAP_COUNT,
|
|
|
|
|
|
|
|
SUM(CASE WHEN DEVICE_TYPE = '2' THEN 1 ELSE 0 END) AS EXPERIMENT_COUNT
|
|
|
|
|
|
|
|
FROM BASE_DEVICELEDGER
|
|
|
|
|
|
|
|
WHERE IS_FLAG = 1
|
|
|
|
|
|
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
**业务逻辑说明**:
|
|
|
|
|
|
|
|
- **DEVICE_STATUS**:0=正常,1=异常,2=报废
|
|
|
|
|
|
|
|
- **DEVICE_TYPE**:'2'=实验设备
|
|
|
|
|
|
|
|
- **IS_FLAG = 1**:仅统计有效设备
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
#### 4.2.6 故障数量曲线
|
|
|
|
|
|
|
|
|
|
|
|
```sql
|
|
|
|
```sql
|
|
|
|
SELECT TO_CHAR(ALARM_BEGIN_TIME, 'DD') AS dateValue,
|
|
|
|
SELECT TO_CHAR(ALARM_BEGIN_TIME, 'DD') AS dateValue,
|
|
|
|
@ -740,11 +830,11 @@ ORDER BY TRUNC(ALARM_BEGIN_TIME)
|
|
|
|
```
|
|
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
**业务逻辑说明**:
|
|
|
|
**业务逻辑说明**:
|
|
|
|
- 数据来源:`DMS_RECORD_ALARM_INFO` 设备报警记录表(由外部设备插入)
|
|
|
|
- **数据来源**:`DMS_RECORD_ALARM_INFO` 设备报警记录表(由外部设备插入)
|
|
|
|
- 时间范围:近30天
|
|
|
|
- **时间范围**:近30天(`ALARM_BEGIN_TIME >= TRUNC(SYSDATE) - 30`)
|
|
|
|
- 分组方式:按日期分组,返回每日告警数量
|
|
|
|
- **分组方式**:按日期分组,返回每日告警数量
|
|
|
|
|
|
|
|
|
|
|
|
#### 4.2.3 产量机台TOP5(替代备件消耗费用TOP5)
|
|
|
|
#### 4.2.7 产量机台TOP5
|
|
|
|
|
|
|
|
|
|
|
|
```sql
|
|
|
|
```sql
|
|
|
|
SELECT * FROM (
|
|
|
|
SELECT * FROM (
|
|
|
|
@ -759,7 +849,7 @@ SELECT * FROM (
|
|
|
|
ROW_NUMBER() OVER (PARTITION BY DEVICE_CODE ORDER BY COLLECT_TIME DESC) AS RN
|
|
|
|
ROW_NUMBER() OVER (PARTITION BY DEVICE_CODE ORDER BY COLLECT_TIME DESC) AS RN
|
|
|
|
FROM BASE_DEVICE_PARAM_VAL
|
|
|
|
FROM BASE_DEVICE_PARAM_VAL
|
|
|
|
WHERE PARAM_NAME = '机台状态-实际产出数量'
|
|
|
|
WHERE PARAM_NAME = '机台状态-实际产出数量'
|
|
|
|
AND TO_CHAR(COLLECT_TIME, 'YYYY-MM-DD') = TO_CHAR(SYSDATE, 'YYYY-MM-DD')
|
|
|
|
AND COLLECT_TIME >= TRUNC(SYSDATE) AND COLLECT_TIME < TRUNC(SYSDATE) + 1
|
|
|
|
)
|
|
|
|
)
|
|
|
|
WHERE RN = 1
|
|
|
|
WHERE RN = 1
|
|
|
|
) p ON d.DEVICE_CODE = p.DEVICE_CODE
|
|
|
|
) p ON d.DEVICE_CODE = p.DEVICE_CODE
|
|
|
|
@ -773,7 +863,7 @@ SELECT * FROM (
|
|
|
|
- 按产量降序排列,取前5名
|
|
|
|
- 按产量降序排列,取前5名
|
|
|
|
- 百分比在Service层计算:`percent = production / maxProduction * 100`
|
|
|
|
- 百分比在Service层计算:`percent = production / maxProduction * 100`
|
|
|
|
|
|
|
|
|
|
|
|
#### 4.2.4 故障来源分布
|
|
|
|
#### 4.2.8 故障来源分布
|
|
|
|
|
|
|
|
|
|
|
|
```sql
|
|
|
|
```sql
|
|
|
|
SELECT COUNT(*) AS TOTAL_COUNT,
|
|
|
|
SELECT COUNT(*) AS TOTAL_COUNT,
|
|
|
|
@ -785,9 +875,10 @@ WHERE IS_FLAG = '1'
|
|
|
|
```
|
|
|
|
```
|
|
|
|
|
|
|
|
|
|
|
|
**业务逻辑说明**:
|
|
|
|
**业务逻辑说明**:
|
|
|
|
- FAULT_SOURCE_TYPE=1(检修)→ 维护故障
|
|
|
|
- **FAULT_SOURCE_TYPE = 1**(检修)→ 维护故障
|
|
|
|
- FAULT_SOURCE_TYPE=2,3(点检/巡检)→ 运行故障
|
|
|
|
- **FAULT_SOURCE_TYPE = 2, 3**(点检/巡检)→ 运行故障
|
|
|
|
- FAULT_SOURCE_TYPE=9(其他)→ 自然故障
|
|
|
|
- **FAULT_SOURCE_TYPE = 9**(其他)→ 自然故障
|
|
|
|
|
|
|
|
- **数据范围**:全量历史数据,`WHERE IS_FLAG = '1'`
|
|
|
|
|
|
|
|
|
|
|
|
---
|
|
|
|
---
|
|
|
|
|
|
|
|
|
|
|
|
@ -845,15 +936,7 @@ export function getProductionTop5() {
|
|
|
|
|
|
|
|
|
|
|
|
## 六、数据库表结构参考
|
|
|
|
## 六、数据库表结构参考
|
|
|
|
|
|
|
|
|
|
|
|
### 6.1 BASE_ORDERINFO(工单表)
|
|
|
|
### 6.1 DMS_BILLS_FAULT_INSTANCE(故障报修工单表)
|
|
|
|
|
|
|
|
|
|
|
|
| 字段 | 类型 | 说明 |
|
|
|
|
|
|
|
|
|------|------|------|
|
|
|
|
|
|
|
|
| OBJ_ID | NUMBER | 主键 |
|
|
|
|
|
|
|
|
| EXECUTION_STATUS | VARCHAR2 | 执行状态(PENDING/RUNNING/COMPLETED/PAUSED) |
|
|
|
|
|
|
|
|
| IS_FLAG | NUMBER | 是否标识(0=有效) |
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
### 6.2 DMS_BILLS_FAULT_INSTANCE(故障报修工单表)
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
| 字段 | 类型 | 说明 |
|
|
|
|
| 字段 | 类型 | 说明 |
|
|
|
|
|------|------|------|
|
|
|
|
|------|------|------|
|
|
|
|
@ -861,48 +944,50 @@ export function getProductionTop5() {
|
|
|
|
| APPLY_TIME | DATE | 申请时间 |
|
|
|
|
| APPLY_TIME | DATE | 申请时间 |
|
|
|
|
| REAL_BEGIN_TIME | DATE | 实际开始时间 |
|
|
|
|
| REAL_BEGIN_TIME | DATE | 实际开始时间 |
|
|
|
|
| REAL_END_TIME | DATE | 实际完成时间 |
|
|
|
|
| REAL_END_TIME | DATE | 实际完成时间 |
|
|
|
|
|
|
|
|
| BILLS_STATUS | CHAR(1) | 工单状态(0待维修,1维修中,2维修完成) |
|
|
|
|
| FAULT_SOURCE_TYPE | NUMBER | 报修来源类型(1检修 2点检 3巡检 9其他) |
|
|
|
|
| FAULT_SOURCE_TYPE | NUMBER | 报修来源类型(1检修 2点检 3巡检 9其他) |
|
|
|
|
| IS_FLAG | CHAR(1) | 激活标识(1是 0否) |
|
|
|
|
| IS_FLAG | CHAR(1) | 激活标识(1是 0否) |
|
|
|
|
|
|
|
|
|
|
|
|
### 6.3 DMS_PLAN_MAINT(保养计划表)
|
|
|
|
### 6.2 DMS_BILLS_MAINT_INSTANCE(保养工单表)
|
|
|
|
|
|
|
|
|
|
|
|
| 字段 | 类型 | 说明 |
|
|
|
|
|
|
|
|
|------|------|------|
|
|
|
|
|
|
|
|
| PLAN_MAINT_ID | NUMBER(20) | 主键 |
|
|
|
|
|
|
|
|
| MAINT_STATUS | NUMBER | 保养状态(1待保养 2保养中 3已完成 4待验证) |
|
|
|
|
|
|
|
|
| IS_FLAG | NUMBER | 是否标识(1是 2否) |
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
### 6.4 DMS_PLAN_INSPECT(巡检计划表)
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
| 字段 | 类型 | 说明 |
|
|
|
|
|
|
|
|
|------|------|------|
|
|
|
|
|
|
|
|
| PLAN_INSPECT_ID | NUMBER(20) | 主键 |
|
|
|
|
|
|
|
|
| DEVICE_AMOUNT | NUMBER | 设备总数 |
|
|
|
|
|
|
|
|
| IS_FLAG | CHAR(1) | 是否标识(1是 0否) |
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
### 6.5 RECORD_ALARM_DEVICE(设备告警记录表)
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
| 字段 | 类型 | 说明 |
|
|
|
|
|
|
|
|
|------|------|------|
|
|
|
|
|
|
|
|
| OBJ_ID | NUMBER(38) | 主键 |
|
|
|
|
|
|
|
|
| DEVICE_CODE | VARCHAR2(128) | 设备编号 |
|
|
|
|
|
|
|
|
| DEVICE_NAME | VARCHAR2(128) | 设备名称 |
|
|
|
|
|
|
|
|
| ALARM_INFO | VARCHAR2(255) | 报警信息 |
|
|
|
|
|
|
|
|
| ALARM_TIME | DATE | 报警时间 |
|
|
|
|
|
|
|
|
| IS_FLAG | NUMBER | 是否标识(0=有效) |
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
### 6.6 BASE_DEVICELEDGER(设备台账表)
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
| 字段 | 类型 | 说明 |
|
|
|
|
| 字段 | 类型 | 说明 |
|
|
|
|
|------|------|------|
|
|
|
|
|------|------|------|
|
|
|
|
| OBJ_ID | NUMBER | 主键 |
|
|
|
|
| OBJ_ID | NUMBER | 主键 |
|
|
|
|
|
|
|
|
| MAINT_STATUS | CHAR(1) | 保养状态(1待保养,2保养中,3已完成) |
|
|
|
|
|
|
|
|
| PLAN_MAINT_ID | NUMBER | 关联的保养计划ID |
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
**注意**:该表无 IS_FLAG 字段,统计时全量查询。
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
### 6.3 DMS_BILLS_INSPECT_INSTANCE(巡检工单表)
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
| 字段 | 类型 | 说明 |
|
|
|
|
|
|
|
|
|------|------|------|
|
|
|
|
|
|
|
|
| OBJ_ID | NUMBER | 主键 |
|
|
|
|
|
|
|
|
| PLAN_INSPECT_ID | NUMBER | 关联的巡检计划ID |
|
|
|
|
|
|
|
|
| INSPECT_STATUS | CHAR(1) | 巡检状态(3已完成) |
|
|
|
|
|
|
|
|
| IS_FLAG | CHAR(1) | 激活标识(1是 0否) |
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
### 6.4 DMS_RECORD_ALARM_INFO(设备告警记录表)
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
| 字段 | 类型 | 说明 |
|
|
|
|
|
|
|
|
|------|------|------|
|
|
|
|
|
|
|
|
| OBJ_ID | NUMBER(38) | 主键 |
|
|
|
|
|
|
|
|
| DEVICE_ID | NUMBER | 设备ID(关联BASE_DEVICELEDGER.OBJ_ID) |
|
|
|
|
|
|
|
|
| ALARM_REASON | VARCHAR2(255) | 报警原因 |
|
|
|
|
|
|
|
|
| ALARM_BEGIN_TIME | DATE | 报警开始时间 |
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
### 6.5 BASE_DEVICELEDGER(设备台账表)
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
| 字段 | 类型 | 说明 |
|
|
|
|
|
|
|
|
|------|------|------|
|
|
|
|
|
|
|
|
| OBJ_ID | NUMBER | 主键(用于关联DMS_BILLS_FAULT_INSTANCE.DEVICE_ID) |
|
|
|
|
| DEVICE_CODE | VARCHAR2(64) | 设备编号 |
|
|
|
|
| DEVICE_CODE | VARCHAR2(64) | 设备编号 |
|
|
|
|
| DEVICE_NAME | VARCHAR2(64) | 设备名称 |
|
|
|
|
| DEVICE_NAME | VARCHAR2(64) | 设备名称 |
|
|
|
|
| DEVICE_STATUS | NUMBER(1,0) | 设备状态(0使用 1停用 2报废) |
|
|
|
|
| DEVICE_STATUS | NUMBER(1,0) | 设备状态(0正常,1异常,2报废) |
|
|
|
|
| DEVICE_TYPE | VARCHAR2(32) | 设备类型(1生产设备 2计量设备) |
|
|
|
|
| DEVICE_TYPE | VARCHAR2(32) | 设备类型(1生产设备,2计量设备) |
|
|
|
|
| IS_FLAG | NUMBER(1,0) | 是否标识(0有效) |
|
|
|
|
| IS_FLAG | NUMBER(1,0) | 是否标识(1有效,0无效) |
|
|
|
|
|
|
|
|
|
|
|
|
### 6.7 BASE_DEVICE_PARAM_VAL(设备工艺参数表)
|
|
|
|
### 6.6 BASE_DEVICE_PARAM_VAL(设备工艺参数表)
|
|
|
|
|
|
|
|
|
|
|
|
| 字段 | 类型 | 说明 |
|
|
|
|
| 字段 | 类型 | 说明 |
|
|
|
|
|------|------|------|
|
|
|
|
|------|------|------|
|
|
|
|
@ -950,19 +1035,20 @@ export function getProductionTop5() {
|
|
|
|
|
|
|
|
|
|
|
|
## 八、注意事项
|
|
|
|
## 八、注意事项
|
|
|
|
|
|
|
|
|
|
|
|
1. **❗重要:故障数量曲线使用 DMS_RECORD_ALARM_INFO 表**
|
|
|
|
1. **❗重要:工单统计使用三类工单表汇总**
|
|
|
|
- 数据来源:`DMS_RECORD_ALARM_INFO` 设备报警记录表(由外部设备插入)
|
|
|
|
- 维修工单:`DMS_BILLS_FAULT_INSTANCE`(WHERE IS_FLAG='1')
|
|
|
|
- 筛选条件:`ALARM_BEGIN_TIME >= TRUNC(SYSDATE) - 30`
|
|
|
|
- 保养工单:`DMS_BILLS_MAINT_INSTANCE`(无 IS_FLAG 字段,全量统计)
|
|
|
|
|
|
|
|
- 巡检工单:`DMS_BILLS_INSPECT_INSTANCE`(WHERE IS_FLAG='1')
|
|
|
|
|
|
|
|
|
|
|
|
2. **❗重要:产量机台TOP5 替代备件消耗费用TOP5**
|
|
|
|
2. **❗重要:巡检应检设备数计算**
|
|
|
|
- 使用 `PARAM_NAME = '机台状态-实际产出数量'` 获取设备产量
|
|
|
|
- 应检设备数 = COUNT(DISTINCT PLAN_INSPECT_ID) × 18
|
|
|
|
- 取每台设备当天最新值,按产量降序排列
|
|
|
|
- 每个巡检计划覆盖18台设备(固定值)
|
|
|
|
|
|
|
|
|
|
|
|
3. **保养状态映射**(DMS_PLAN_MAINT.MAINT_STATUS):
|
|
|
|
3. **保养状态映射**(DMS_BILLS_MAINT_INSTANCE.MAINT_STATUS):
|
|
|
|
- 1 = 待保养
|
|
|
|
- 1 = 待保养
|
|
|
|
- 2 = 保养中
|
|
|
|
- 2 = 保养中
|
|
|
|
- 3 = 已完成
|
|
|
|
- 3 = 已完成
|
|
|
|
- 4 = 待验证
|
|
|
|
- 无 MAINT_STATUS=4 状态,verifyCount 固定返回 0
|
|
|
|
|
|
|
|
|
|
|
|
4. **故障来源类型映射**(DMS_BILLS_FAULT_INSTANCE.FAULT_SOURCE_TYPE):
|
|
|
|
4. **故障来源类型映射**(DMS_BILLS_FAULT_INSTANCE.FAULT_SOURCE_TYPE):
|
|
|
|
- 1 = 检修 → 维护故障
|
|
|
|
- 1 = 检修 → 维护故障
|
|
|
|
@ -971,8 +1057,8 @@ export function getProductionTop5() {
|
|
|
|
- 9 = 其他 → 自然故障
|
|
|
|
- 9 = 其他 → 自然故障
|
|
|
|
|
|
|
|
|
|
|
|
5. **设备表字段类型**(BASE_DEVICELEDGER):
|
|
|
|
5. **设备表字段类型**(BASE_DEVICELEDGER):
|
|
|
|
- `DEVICE_STATUS`:NUMBER(1,0),查询时使用 `= 0`
|
|
|
|
- `DEVICE_STATUS`:NUMBER(1,0),查询时使用 `= 0/1/2`
|
|
|
|
- `IS_FLAG`:NUMBER(1,0),查询时使用 `= 0`
|
|
|
|
- `IS_FLAG`:NUMBER(1,0),值可以是 0 或 1(不同接口使用不同值)
|
|
|
|
|
|
|
|
|
|
|
|
6. **前端页面字段映射**:
|
|
|
|
6. **前端页面字段映射**:
|
|
|
|
- text1-text4 → orderWorkStatistics(工单总数、已完成、完成率、停机工单)
|
|
|
|
- text1-text4 → orderWorkStatistics(工单总数、已完成、完成率、停机工单)
|
|
|
|
@ -992,5 +1078,6 @@ export function getProductionTop5() {
|
|
|
|
|------|------|----------|------|
|
|
|
|
|------|------|----------|------|
|
|
|
|
| 2026-01-21 | 1.0 | Board5看板接口初始版本 | YinQ |
|
|
|
|
| 2026-01-21 | 1.0 | Board5看板接口初始版本 | YinQ |
|
|
|
|
| 2026-01-21 | 1.1 | 故障数量曲线使用RECORD_ALARM_DEVICE表真实数据 | YinQ |
|
|
|
|
| 2026-01-21 | 1.1 | 故障数量曲线使用RECORD_ALARM_DEVICE表真实数据 | YinQ |
|
|
|
|
| 2026-01-22 | 1.3 | 故障数量曲线切换为DMS_RECORD_ALARM_INFO表 | YinQ |
|
|
|
|
|
|
|
|
| 2026-01-21 | 1.2 | 产量机台TOP5替代备件消耗费用TOP5 | YinQ |
|
|
|
|
| 2026-01-21 | 1.2 | 产量机台TOP5替代备件消耗费用TOP5 | YinQ |
|
|
|
|
|
|
|
|
| 2026-01-22 | 1.3 | 故障数量曲线切换为DMS_RECORD_ALARM_INFO表 | YinQ |
|
|
|
|
|
|
|
|
| 2026-01-26 | 2.0 | 根据Mapper XML更新业务逻辑:工单统计改用工单表汇总、保养/巡检改用工单实例表、更新所有SQL示例和表结构 | Claude |
|
|
|
|
|