Bonus-Cloud-Material-Mall/bonus-modules/bonus-material-mall/src/main/resources/mapper/material/cityScreen/CityScreenMapper.xml

279 lines
12 KiB
XML
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

<?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.bonus.material.cityScreen.mapper.CityScreenMapper">
<select id="getDeviceData" resultType="com.bonus.material.cityScreen.VO.BasicTitleVO">
SELECT
count( 1 ) AS totalCount,
IFNULL(sum( buy_price * device_count ),0) AS totalValue
FROM
ma_dev_info
WHERE is_active = 1 and on_company = #{companyId} and entry_status = '1' and change_status !='4'
</select>
<select id="getTodayDeviceEnterOutNum" resultType="com.bonus.material.cityScreen.VO.BasicTitleVO">
select
count( type = 1 ) AS enterNum,
count( type = 2 ) AS outNum
from cs_device_change
where del_flag = 0 and use_unit = #{companyId}
</select>
<select id="equipmentQuantityValue" resultType="com.bonus.material.cityScreen.VO.EquipmentQuantityVO">
SELECT
ifnull(sum(mdi.buy_price * mdi.device_count),0) as totalValue,
COUNT(1) as deviceQuantity
from ma_dev_info mdi
INNER join ma_type_view mtv on mtv.typeId = mdi.type_id
where mdi.is_active = 1 and mtv.MaxTypeId = #{typeId} and mdi.on_company = #{companyId}
<if test="year == 1">
and TIMESTAMPDIFF(YEAR,mdi.production_date, NOW()) <![CDATA[ < ]]> 5
</if>
<if test="year == 2">
and TIMESTAMPDIFF(YEAR, mdi.production_date, NOW()) BETWEEN 5 AND 10
</if>
<if test="year == 3">
and TIMESTAMPDIFF(YEAR, mdi.production_date, NOW()) > 10
</if>
</select>
<select id="selectTypeIdList" resultType="java.lang.Integer">
SELECT
dict_value
from sys_dict_data
where dict_type = 'config_type' and dict_label in ('线路','电缆','变电') and status = '0'
</select>
<select id="getDeviceInfo" resultType="com.bonus.material.cityScreen.entity.DeviceInfoEntity">
select
mdi.device_name as deviceName,
mdi.change_status as status,
mtv.maxTypeId as typeId
from ma_dev_info mdi
INNER join ma_type_view mtv on mtv.typeId = mdi.type_id
where mdi.is_active = 1 and mdi.on_company = #{companyId}
<if test="typeId != null">
and mtv.MaxTypeId = #{typeId}
</if>
<if test="status != null">
<if test="status == 9">
and mdi.change_status != 4
</if>
<if test="status != 2 and status != 9">
and mdi.change_status = #{status}
</if>
<if test="status == 2">
and mdi.change_status = 2 or mdi.change_status = 3
</if>
</if>
</select>
<select id="maintenanceAlarm" resultType="com.bonus.material.cityScreen.VO.AlarmVO">
select
mdi.device_name as deviceName,
mtv.devCategory as procedureName,
case when TIMESTAMPDIFF(DAY, NOW(),mdq.next_check_time) > 30 then '正常'
when TIMESTAMPDIFF(DAY, NOW(),mdq.next_check_time) between 0 and 30 then '1月内到期'
when TIMESTAMPDIFF(DAY, NOW(),mdq.next_check_time) <![CDATA[ < ]]> 0 then '已超期'
else '未检' end as situation
from ma_dev_info mdi
INNER join ma_type_view mtv on mtv.typeId = mdi.type_id
left join ma_dev_qc mdq on mdq.ma_id = mdi.ma_id
where mdi.is_active = 1 and mdi.on_company = #{companyId} and mdi.change_status != 4
order by TIMESTAMPDIFF(YEAR, NOW(),mdq.next_check_time)
</select>
<select id="countMaintenanceAlarm" resultType="int">
select
count(DISTINCT mdi.ma_id)
from ma_dev_info mdi
INNER join ma_type_view mtv on mtv.typeId = mdi.type_id
left join ma_dev_qc mdq on mdq.ma_id = mdi.ma_id
where mdi.is_active = 1 and mdi.on_company = #{companyId} and mdi.change_status != 4
</select>
<select id="retirementAlarm" resultType="com.bonus.material.cityScreen.VO.AlarmVO">
SELECT
mdi.device_name AS deviceName,
mtv.devCategory AS procedureName,
-- 核心:按「剩余可用年限」判断状态(剩余年限 = 最大年限 - 已使用年限)
CASE
-- 告警2已超期剩余年限≤0
WHEN ROUND(TIMESTAMPDIFF(DAY, mdi.production_date, NOW()) / 365.25, 1) &gt;= mdi.max_working_hours
THEN CONCAT('告警:已超最大使用年限', ROUND(
ROUND(TIMESTAMPDIFF(DAY, mdi.production_date, NOW()) / 365.25, 1) - mdi.max_working_hours,
1
), '年')
-- 告警1未超期但剩余可用年限≤1年相差小于等于1年
WHEN (mdi.max_working_hours - ROUND(TIMESTAMPDIFF(DAY, mdi.production_date, NOW()) / 365.25, 1)) &lt;= 1
THEN CONCAT('告警:即将超期,剩余可用年限', ROUND(
mdi.max_working_hours - ROUND(TIMESTAMPDIFF(DAY, mdi.production_date, NOW()) / 365.25, 1),
1
), '年')
-- 正常未超期且剩余可用年限1年相差大于1年
ELSE CONCAT('正常:剩余可用年限', ROUND(
mdi.max_working_hours - ROUND(TIMESTAMPDIFF(DAY, mdi.production_date, NOW()) / 365.25, 1),
1
), '年')
END AS situation
FROM
ma_dev_info mdi
INNER JOIN ma_type_view mtv
ON mtv.typeId = mdi.type_id
WHERE
mdi.is_active = 1
AND mdi.on_company = #{companyId} -- MyBatis 参数占位符(安全防注入)
AND mdi.change_status != 4
-- 排序:超期告警>即将超期告警>正常(按紧急程度)
ORDER BY
CASE
-- 超期告警优先级1
WHEN ROUND(TIMESTAMPDIFF(DAY, mdi.production_date, NOW()) / 365.25, 1) &gt;= mdi.max_working_hours THEN 0
-- 即将超期告警优先级2
WHEN (mdi.max_working_hours - ROUND(TIMESTAMPDIFF(DAY, mdi.production_date, NOW()) / 365.25, 1)) &lt;= 1 THEN 1
-- 正常优先级3
ELSE 2
END ASC,
-- 超期告警:超期越久越靠前
(ROUND(TIMESTAMPDIFF(DAY, mdi.production_date, NOW()) / 365.25, 1) - mdi.max_working_hours) DESC,
-- 即将超期告警:剩余年限越少越靠前
(mdi.max_working_hours - ROUND(TIMESTAMPDIFF(DAY, mdi.production_date, NOW()) / 365.25, 1)) ASC
</select>
<select id="countRetirementAlarm" resultType="int">
select
count(DISTINCT mdi.ma_id)
from ma_dev_info mdi
INNER join ma_type_view mtv on mtv.typeId = mdi.type_id
where mdi.is_active = 1 and mdi.on_company = #{companyId} and mdi.change_status != 4
</select>
<select id="countEquipmentTurnoverRate" resultType="int">
select
count(1)
from ma_dev_info mdi
INNER join ma_type_view mtv on mtv.typeId = mdi.type_id
where mdi.is_active = 1 and mdi.on_company = #{companyId} and mdi.change_status != 3
</select>
<select id="equipmentTurnoverRate" resultType="com.bonus.material.cityScreen.VO.EquipmentTurnoverRateVO">
select
mtv.proType as major,
mtv.mainGx as mainProcess,
mtv.childGx as subprocess,
mdi.device_name as deviceName,
CONCAT(ROUND(count(cdcd.dev_id)/mdi.device_count, 2),'次/年') as turnoverRate
from ma_dev_info mdi
INNER join ma_type_view mtv on mtv.typeId = mdi.type_id
left join cs_device_change_details cdcd on cdcd.dev_id = mdi.ma_id
left join cs_device_change cdc on cdc.id = cdcd.change_id
where mdi.is_active = 1 and mdi.on_company = #{companyId} and mdi.change_status != 4 and cdc.type = 2 and cdc.del_flag = 0
and TIMESTAMPDIFF(MONTH , NOW(),cdc.create_time) between 0 and 12
group by mtv.proType, mtv.mainGx, mtv.childGx, mdi.device_name
order by turnoverRate desc
</select>
<select id="equipmentInUseInTheProject" resultType="com.bonus.material.cityScreen.VO.EquipmentUseVO">
select DISTINCT
jsp.pro_name as projectName,
sum(mdi.device_count) as useNum,
sum(mdi.buy_price * mdi.device_count) as investAmount
from jj_sing_project jsp
left join ma_dev_info mdi on mdi.on_project = jsp.id
INNER join ma_type_view mtv on mtv.typeId = mdi.type_id
where mdi.is_active = 1 and mdi.on_company = #{companyId} and mdi.change_status in (2,3)
<if test="voltageLevel != null">
and jsp.voltage = #{voltageLevel}
</if>
<if test="typeId != null">
and mtv.maxTypeId = #{typeId}
</if>
group by jsp.id,jsp.pro_name
</select>
<select id="countProNum" resultType="int">
select count(1)
from(
select DISTINCT count(1)
from jj_sing_project jsp
left join ma_dev_info mdi on mdi.on_project = jsp.id
INNER join ma_type_view mtv on mtv.typeId = mdi.type_id
where mdi.is_active = 1
and mdi.on_company = #{companyId}
and mdi.change_status in (2, 3)
<if test="voltageLevel != null">
and jsp.voltage = #{voltageLevel}
</if>
<if test="typeId != null">
and mtv.maxTypeId = #{typeId}
</if>
group by jsp.id
)r
</select>
<select id="countUseNum" resultType="int">
select
IFNULL(sum(r.num),0) as useNum
from(
select DISTINCT ifnull(sum(mdi.device_count),0) as num
from jj_sing_project jsp
left join ma_dev_info mdi on mdi.on_project = jsp.id
INNER join ma_type_view mtv on mtv.typeId = mdi.type_id
where mdi.is_active = 1
and mdi.on_company = #{companyId}
and mdi.change_status in (2, 3)
<if test="voltageLevel != null">
and jsp.voltage = #{voltageLevel}
</if>
<if test="typeId != null">
and mtv.maxTypeId = #{typeId}
</if>
group by jsp.id
)r
</select>
<select id="proList" resultType="com.bonus.material.cityScreen.VO.ProVO">
select DISTINCT
jsp.pro_name as projectName,
jsp.city as city,
jsp.county as county,
jsp.lon as lon,
jsp.lat as lat,
sum(mdi.device_count) as useNum
from jj_sing_project jsp
left join ma_dev_info mdi on mdi.on_project = jsp.id
INNER join ma_type_view mtv on mtv.typeId = mdi.type_id
<!-- left join coordinate_point cp on cp.name = jsp.county-->
where mdi.is_active = 1
<!-- and mdi.change_status in (2,3)-->
and jsp.city = #{city}
group by jsp.id
</select>
<select id="countDeviceNum" resultType="int">
select ifnull(sum(r.useNum),0) as useNum
from(
select DISTINCT
ifnull(sum(mdi.device_count),0) as useNum
from jj_sing_project jsp
left join ma_dev_info mdi on mdi.on_project = jsp.id
INNER join ma_type_view mtv on mtv.typeId = mdi.type_id
where mdi.is_active = 1
and mdi.change_status in (1,5)
and jsp.city = #{city}
)r
</select>
<select id="countOutDeviceNum" resultType="int">
select ifnull(sum(r.useNum), 0) as useNum
from (select DISTINCT ifnull(sum(mdi.device_count), 0) as useNum
from jj_sing_project jsp
left join ma_dev_info mdi on mdi.on_project = jsp.id
INNER join ma_type_view mtv on mtv.typeId = mdi.type_id
where mdi.is_active = 1
and (mdi.change_status in (2, 3) or mdi.change_status is null)
and jsp.city != #{city}) r
</select>
</mapper>