|
|
<?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="com.aucma.base.mapper.BaseDeviceParamValMapper">
|
|
|
|
|
|
<resultMap type="BaseDeviceParamVal" id="BaseDeviceParamValResult">
|
|
|
<result property="recordId" column="record_id" />
|
|
|
<result property="paramCode" column="param_code" />
|
|
|
<result property="deviceCode" column="device_code" />
|
|
|
<result property="deviceId" column="device_id" />
|
|
|
<result property="paramName" column="param_name" />
|
|
|
<result property="paramValue" column="param_value" />
|
|
|
<result property="collectTime" column="collect_time" />
|
|
|
<result property="recordTime" column="record_time" />
|
|
|
</resultMap>
|
|
|
|
|
|
<sql id="selectBaseDeviceParamValVo">
|
|
|
select record_id, param_code, device_code, device_id, param_name, param_value,
|
|
|
collect_time, record_time
|
|
|
from base_device_param_val
|
|
|
</sql>
|
|
|
|
|
|
<select id="selectBaseDeviceParamValList" parameterType="BaseDeviceParamVal" resultMap="BaseDeviceParamValResult">
|
|
|
<include refid="selectBaseDeviceParamValVo"/>
|
|
|
<where>
|
|
|
<if test="paramCode != null and paramCode != ''"> and param_code = #{paramCode}</if>
|
|
|
<if test="deviceCode != null and deviceCode != ''"> and device_code = #{deviceCode}</if>
|
|
|
<if test="deviceId != null "> and device_id = #{deviceId}</if>
|
|
|
<if test="paramName != null and paramName != ''"> and param_name like concat(concat('%', #{paramName}), '%')</if>
|
|
|
<if test="paramValue != null and paramValue != ''"> and param_value = #{paramValue}</if>
|
|
|
<if test="collectTime != null "> and collect_time = #{collectTime}</if>
|
|
|
<if test="recordTime != null "> and record_time = #{recordTime}</if>
|
|
|
</where>
|
|
|
</select>
|
|
|
|
|
|
<select id="selectBaseDeviceParamValByRecordId" parameterType="Long" resultMap="BaseDeviceParamValResult">
|
|
|
<include refid="selectBaseDeviceParamValVo"/>
|
|
|
where record_id = #{recordId}
|
|
|
</select>
|
|
|
|
|
|
<insert id="insertBaseDeviceParamVal" parameterType="BaseDeviceParamVal">
|
|
|
<selectKey keyProperty="recordId" resultType="long" order="BEFORE">
|
|
|
SELECT seq_base_device_param_val.NEXTVAL as recordId FROM DUAL
|
|
|
</selectKey>
|
|
|
insert into base_device_param_val
|
|
|
<trim prefix="(" suffix=")" suffixOverrides=",">
|
|
|
<if test="recordId != null">record_id,</if>
|
|
|
<if test="paramCode != null">param_code,</if>
|
|
|
<if test="deviceCode != null">device_code,</if>
|
|
|
<if test="deviceId != null">device_id,</if>
|
|
|
<if test="paramName != null">param_name,</if>
|
|
|
<if test="paramValue != null">param_value,</if>
|
|
|
<if test="collectTime != null">collect_time,</if>
|
|
|
<if test="recordTime != null">record_time,</if>
|
|
|
</trim>
|
|
|
<trim prefix="values (" suffix=")" suffixOverrides=",">
|
|
|
<if test="recordId != null">#{recordId},</if>
|
|
|
<if test="paramCode != null">#{paramCode},</if>
|
|
|
<if test="deviceCode != null">#{deviceCode},</if>
|
|
|
<if test="deviceId != null">#{deviceId},</if>
|
|
|
<if test="paramName != null">#{paramName},</if>
|
|
|
<if test="paramValue != null">#{paramValue},</if>
|
|
|
<if test="collectTime != null">#{collectTime},</if>
|
|
|
<if test="recordTime != null">#{recordTime},</if>
|
|
|
</trim>
|
|
|
</insert>
|
|
|
|
|
|
<update id="updateBaseDeviceParamVal" parameterType="BaseDeviceParamVal">
|
|
|
update base_device_param_val
|
|
|
<trim prefix="SET" suffixOverrides=",">
|
|
|
<if test="paramCode != null">param_code = #{paramCode},</if>
|
|
|
<if test="deviceCode != null">device_code = #{deviceCode},</if>
|
|
|
<if test="deviceId != null">device_id = #{deviceId},</if>
|
|
|
<if test="paramName != null">param_name = #{paramName},</if>
|
|
|
<if test="paramValue != null">param_value = #{paramValue},</if>
|
|
|
<if test="collectTime != null">collect_time = #{collectTime},</if>
|
|
|
<if test="recordTime != null">record_time = #{recordTime},</if>
|
|
|
</trim>
|
|
|
where record_id = #{recordId}
|
|
|
</update>
|
|
|
|
|
|
<delete id="deleteBaseDeviceParamValByRecordId" parameterType="Long">
|
|
|
delete from base_device_param_val where record_id = #{recordId}
|
|
|
</delete>
|
|
|
|
|
|
<delete id="deleteBaseDeviceParamValByRecordIds" parameterType="String">
|
|
|
delete from base_device_param_val where record_id in
|
|
|
<foreach item="recordId" collection="array" open="(" separator="," close=")">
|
|
|
#{recordId}
|
|
|
</foreach>
|
|
|
</delete>
|
|
|
|
|
|
<!-- 最新参数聚合查询:每设备每参数取最新一条记录,限制返回200条 -->
|
|
|
<!-- <select id="selectLatestBaseDeviceParamValList" parameterType="BaseDeviceParamVal" resultMap="BaseDeviceParamValResult">
|
|
|
SELECT * FROM (
|
|
|
SELECT
|
|
|
record_id, param_code, device_code, device_id, param_name, param_value, collect_time, record_time,
|
|
|
ROW_NUMBER() OVER (ORDER BY device_code, param_code) AS row_num
|
|
|
FROM (
|
|
|
SELECT
|
|
|
record_id, param_code, device_code, device_id, param_name, param_value, collect_time, record_time,
|
|
|
ROW_NUMBER() OVER (PARTITION BY device_code, param_code ORDER BY NVL(record_time, collect_time) DESC) AS rn
|
|
|
FROM base_device_param_val
|
|
|
<where>
|
|
|
<if test="deviceCode != null and deviceCode != ''">and device_code = #{deviceCode}</if>
|
|
|
<if test="paramCode != null and paramCode != ''">and param_code = #{paramCode}</if>
|
|
|
<if test="deviceId != null">and device_id = #{deviceId}</if>
|
|
|
<if test="paramName != null and paramName != ''">and param_name like '%' || #{paramName} || '%'</if>
|
|
|
</where>
|
|
|
) WHERE rn = 1
|
|
|
) WHERE row_num <= 200
|
|
|
</select> -->
|
|
|
<select id="selectLatestBaseDeviceParamValList" parameterType="BaseDeviceParamVal" resultMap="BaseDeviceParamValResult">
|
|
|
SELECT *
|
|
|
FROM (
|
|
|
SELECT
|
|
|
record_id, param_code, device_code, device_id, param_name, param_value,
|
|
|
collect_time, record_time,
|
|
|
ROW_NUMBER() OVER (ORDER BY device_code, param_code) AS row_num
|
|
|
FROM (
|
|
|
SELECT
|
|
|
record_id, param_code, device_code, device_id, param_name, param_value,
|
|
|
collect_time, record_time,
|
|
|
ROW_NUMBER() OVER (PARTITION BY device_code, param_code ORDER BY NVL(record_time, collect_time) DESC) AS rn
|
|
|
FROM base_device_param_val B
|
|
|
WHERE 1=1
|
|
|
<if test="deviceCode != null and deviceCode != ''">AND device_code = #{deviceCode}</if>
|
|
|
<if test="paramCode != null and paramCode != ''">AND param_code = #{paramCode}</if>
|
|
|
<if test="deviceId != null">AND device_id = #{deviceId}</if>
|
|
|
<if test="paramName != null and paramName != ''">AND param_name LIKE '%' || #{paramName} || '%'</if>
|
|
|
<!-- 强烈建议增加时间窗口 -->
|
|
|
<if test="beginTime != null and endTime != null">
|
|
|
AND NVL(record_time, collect_time) BETWEEN #{beginTime} AND #{endTime}
|
|
|
</if>
|
|
|
) WHERE rn = 1
|
|
|
) WHERE row_num <= 200
|
|
|
</select>
|
|
|
|
|
|
<!-- 设备状态统计:基于三色灯参数获取设备运行状态统计 -->
|
|
|
<select id="selectDeviceStatusStatistics" resultType="java.util.Map">
|
|
|
WITH today_latest AS (
|
|
|
SELECT /*+ PARALLEL(4) */
|
|
|
device_code,
|
|
|
param_name,
|
|
|
ROW_NUMBER() OVER (PARTITION BY device_code ORDER BY NVL(record_time, collect_time) DESC) AS rn
|
|
|
FROM base_device_param_val
|
|
|
WHERE param_name IN ('机台状态-三色灯机器运行', '机台状态-三色灯机器暂停', '机台状态-三色灯机器待机', '机台状态-三色灯机器报警')
|
|
|
AND collect_time >= TRUNC(SYSDATE) AND collect_time < TRUNC(SYSDATE) + 1
|
|
|
),
|
|
|
device_status AS (
|
|
|
SELECT device_code, param_name FROM today_latest WHERE rn = 1
|
|
|
),
|
|
|
status_sum AS (
|
|
|
SELECT
|
|
|
NVL(SUM(CASE WHEN param_name = '机台状态-三色灯机器运行' THEN 1 ELSE 0 END), 0) AS runningCount,
|
|
|
NVL(SUM(CASE WHEN param_name = '机台状态-三色灯机器暂停' THEN 1 ELSE 0 END), 0) AS stoppedCount,
|
|
|
NVL(SUM(CASE WHEN param_name = '机台状态-三色灯机器待机' THEN 1 ELSE 0 END), 0) AS standbyCount,
|
|
|
NVL(SUM(CASE WHEN param_name = '机台状态-三色灯机器报警' THEN 1 ELSE 0 END), 0) AS alarmCount
|
|
|
FROM device_status
|
|
|
),
|
|
|
total_cnt AS (
|
|
|
SELECT COUNT(1) AS totalCount FROM base_deviceledger WHERE is_flag = 1
|
|
|
)
|
|
|
SELECT
|
|
|
t.totalCount,
|
|
|
s.runningCount,
|
|
|
s.stoppedCount,
|
|
|
s.standbyCount,
|
|
|
s.alarmCount,
|
|
|
t.totalCount - s.runningCount - s.stoppedCount - s.standbyCount - s.alarmCount AS notStartedCount
|
|
|
FROM status_sum s, total_cnt t
|
|
|
</select>
|
|
|
|
|
|
<!-- 获取每个设备的编号、名称、三色灯状态 -->
|
|
|
<select id="selectDeviceStatusList" resultType="java.util.Map">
|
|
|
WITH today_latest AS (
|
|
|
SELECT /*+ PARALLEL(4) */
|
|
|
device_code,
|
|
|
param_name,
|
|
|
ROW_NUMBER() OVER (PARTITION BY device_code ORDER BY NVL(record_time, collect_time) DESC) AS rn
|
|
|
FROM base_device_param_val
|
|
|
WHERE param_name IN ('机台状态-三色灯机器运行', '机台状态-三色灯机器暂停', '机台状态-三色灯机器待机','机台状态-三色灯机器报警')
|
|
|
AND collect_time >= TRUNC(SYSDATE) AND collect_time < TRUNC(SYSDATE) + 1
|
|
|
),
|
|
|
device_status AS (
|
|
|
SELECT device_code, param_name FROM today_latest WHERE rn = 1
|
|
|
)
|
|
|
SELECT
|
|
|
d.device_code AS deviceCode,
|
|
|
d.device_name AS deviceName,
|
|
|
d.product_line_code AS productLineCode,
|
|
|
CASE
|
|
|
WHEN s.param_name = '机台状态-三色灯机器运行' THEN '运行'
|
|
|
WHEN s.param_name = '机台状态-三色灯机器暂停' THEN '停机'
|
|
|
WHEN s.param_name = '机台状态-三色灯机器待机' THEN '待机'
|
|
|
WHEN s.param_name = '机台状态-三色灯机器报警' THEN '报警'
|
|
|
ELSE '未开机'
|
|
|
END AS deviceStatus,
|
|
|
CASE
|
|
|
WHEN s.param_name = '机台状态-三色灯机器运行' THEN 1
|
|
|
WHEN s.param_name = '机台状态-三色灯机器暂停' THEN 2
|
|
|
WHEN s.param_name = '机台状态-三色灯机器待机' THEN 3
|
|
|
WHEN s.param_name = '机台状态-三色灯机器报警' THEN 4
|
|
|
ELSE 0
|
|
|
END AS statusCode
|
|
|
FROM base_deviceledger d
|
|
|
LEFT JOIN device_status s ON d.device_code = s.device_code
|
|
|
WHERE d.is_flag = 1
|
|
|
ORDER BY d.product_line_code, d.device_code
|
|
|
</select>
|
|
|
|
|
|
<!-- 获取每个设备的开机时间当天最新值 -->
|
|
|
<select id="selectDeviceStartTimeList" resultType="java.util.Map">
|
|
|
WITH today_latest AS (
|
|
|
SELECT /*+ PARALLEL(4) */
|
|
|
device_code,
|
|
|
param_value,
|
|
|
ROW_NUMBER() OVER (PARTITION BY device_code ORDER BY NVL(record_time, collect_time) DESC) AS rn
|
|
|
FROM base_device_param_val
|
|
|
WHERE param_name = '机台状态-开机时间'
|
|
|
AND collect_time >= TRUNC(SYSDATE) AND collect_time < TRUNC(SYSDATE) + 1
|
|
|
)
|
|
|
SELECT
|
|
|
d.device_code AS deviceCode,
|
|
|
d.device_name AS deviceName,
|
|
|
d.product_line_code AS productLineCode,
|
|
|
NVL(t.param_value, '') AS startTime
|
|
|
FROM base_deviceledger d
|
|
|
LEFT JOIN today_latest t ON d.device_code = t.device_code AND t.rn = 1
|
|
|
WHERE d.is_flag = 1
|
|
|
ORDER BY d.product_line_code, d.device_code
|
|
|
</select>
|
|
|
|
|
|
<!-- 参数追溯查询(按时间范围,必须带设备和时间条件) -->
|
|
|
<select id="selectTraceList" parameterType="java.util.Map" resultMap="BaseDeviceParamValResult">
|
|
|
SELECT * FROM (
|
|
|
SELECT record_id, param_code, device_code, device_id, param_name, param_value,
|
|
|
collect_time, record_time,
|
|
|
ROW_NUMBER() OVER (ORDER BY collect_time DESC) AS rn
|
|
|
FROM base_device_param_val
|
|
|
WHERE device_code = #{deviceCode}
|
|
|
AND collect_time BETWEEN TO_DATE(#{startTime}, 'YYYY-MM-DD HH24:MI:SS')
|
|
|
AND TO_DATE(#{endTime}, 'YYYY-MM-DD HH24:MI:SS')
|
|
|
<if test="paramCode != null and paramCode != ''">
|
|
|
AND param_code = #{paramCode}
|
|
|
</if>
|
|
|
) WHERE rn <= 10000
|
|
|
ORDER BY collect_time DESC
|
|
|
</select>
|
|
|
|
|
|
<!-- SPC分析数据查询(参数历史值,限制1000条) -->
|
|
|
<select id="selectParamHistoryValues" parameterType="java.util.Map" resultType="java.lang.Double">
|
|
|
SELECT * FROM (
|
|
|
SELECT TO_NUMBER(param_value) AS param_value
|
|
|
FROM base_device_param_val
|
|
|
WHERE device_code = #{deviceCode}
|
|
|
AND param_code = #{paramCode}
|
|
|
AND collect_time BETWEEN TO_DATE(#{startTime}, 'YYYY-MM-DD HH24:MI:SS')
|
|
|
AND TO_DATE(#{endTime}, 'YYYY-MM-DD HH24:MI:SS')
|
|
|
AND REGEXP_LIKE(param_value, '^-?[0-9]+\.?[0-9]*$')
|
|
|
ORDER BY collect_time ASC
|
|
|
) WHERE ROWNUM <= 1000
|
|
|
</select>
|
|
|
|
|
|
<!-- 查询参数名称 -->
|
|
|
<select id="selectParamNameByCode" parameterType="String" resultType="String">
|
|
|
SELECT param_name FROM (
|
|
|
SELECT param_name FROM base_device_param_val
|
|
|
WHERE param_code = #{paramCode} AND ROWNUM = 1
|
|
|
)
|
|
|
</select>
|
|
|
</mapper> |