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

380 lines
18 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.equipment.mapper.SysDeptMapper">
<sql id="selectDeptVo">
select d.dept_id,
d.parent_id,
d.dept_name,
d.order_num,
d.leader,
d.dept_abbreviation,
d.dept_type,
d.location,
d.phone,
d.status,
d.del_flag,
d.city
from sys_dept d
</sql>
<resultMap type="com.bonus.system.api.domain.SysDept" id="SysDeptResult">
<id property="deptId" column="dept_id" />
<result property="parentId" column="parent_id" />
<result property="ancestors" column="ancestors" />
<result property="deptName" column="dept_name" />
<result property="orderNum" column="order_num" />
<result property="leader" column="leader" />
<result property="phone" column="phone" />
<result property="email" column="email" />
<result property="status" column="status" />
<result property="delFlag" column="del_flag" />
<result property="parentName" column="parent_name" />
<result property="createBy" column="create_by" />
<result property="createTime" column="create_time" />
<result property="updateBy" column="update_by" />
<result property="updateTime" column="update_time" />
<result property="menuTemplateId" column="menu_template_id" />
<result property="province" column="province" />
<result property="city" column="city" />
<result property="district" column="district" />
<result property="address" column="address" />
<result property="deptAbbreviation" column="dept_abbreviation" />
<result property="remark" column="remark" />
<result property="logo" column="logo" />
<result property="adminUserId" column="admin_user_id" />
<result property="initPassword" column="init_password" />
</resultMap>
<resultMap type="com.bonus.material.basic.domain.SysDeptVO" id="SysDeptVOResult">
<id property="deptId" column="dept_id" />
<result property="parentId" column="parent_id" />
<result property="ancestors" column="ancestors" />
<result property="deptName" column="dept_name" />
<result property="orderNum" column="order_num" />
<result property="leader" column="leader" />
<result property="phone" column="phone" />
<result property="email" column="email" />
<result property="status" column="status" />
<result property="delFlag" column="del_flag" />
<result property="parentName" column="parent_name" />
<result property="createBy" column="create_by" />
<result property="createTime" column="create_time" />
<result property="updateBy" column="update_by" />
<result property="updateTime" column="update_time" />
<result property="menuTemplateId" column="menu_template_id" />
<result property="province" column="province" />
<result property="city" column="city" />
<result property="district" column="district" />
<result property="address" column="address" />
<result property="deptAbbreviation" column="dept_abbreviation" />
<result property="remark" column="remark" />
<result property="logo" column="logo" />
<result property="adminUserId" column="admin_user_id" />
<result property="initPassword" column="init_password" />
</resultMap>
<select id="selectDeptTree" resultType="com.bonus.material.equipment.domain.SysDept">
SELECT * FROM sys_dept WHERE del_flag = '0' ORDER BY parent_id, order_num
</select>
<select id="selectDeptList" parameterType="com.bonus.system.api.domain.SysDept" resultMap="SysDeptResult">
<include refid="selectDeptVo"/>
where d.del_flag = '0'
<if test="deptName != null and deptName != ''">
AND dept_name like concat('%', #{deptName}, '%')
</if>
</select>
<select id="selectDeptVOList" resultMap="SysDeptVOResult">
<include refid="selectDeptVo"/>
where d.del_flag = '0'
<if test="deptName != null and deptName != ''">
AND dept_name like concat('%', #{deptName}, '%')
</if>
</select>
<select id="selectUserList" resultType="com.bonus.material.equipment.domain.DeptEquipmentConfig">
SELECT
t.equipmentId,
t.equipmentName,
t.equipmenttype,
t.jijuType,
t.configStatus
FROM (
-- 原SQL的第一部分设备5/6级节点
SELECT
mtv.typeId AS equipmentId,
CASE
WHEN mtv.actual_level = 5 THEN CONCAT_WS('>', mtv.proType, mtv.mainGx, mtv.childGx, mtv.devCategory)
WHEN mtv.actual_level = 6 THEN CONCAT_WS('>', mtv.proType, mtv.mainGx, mtv.childGx, mtv.devCategory,
mtv.devSubcategory)
ELSE CONCAT_WS('>', mtv.proType, mtv.mainGx, mtv.childGx, mtv.devCategory, mtv.devSubcategory)
END AS equipmentName,
CASE
WHEN mtv.actual_level = 5 THEN mtv.devSubcategory
WHEN mtv.actual_level = 6 THEN mtv.devName
ELSE CONCAT_WS('>', mtv.proType, mtv.mainGx, mtv.childGx, mtv.devCategory, mtv.devSubcategory)
END AS equipmenttype,
'1' as jijuType,
IF(MAX(mdc.config_value) IS NOT NULL AND MAX(mdc.config_value) != '', '已配置', '未配置') AS configStatus
FROM
ma_type_view mtv
LEFT JOIN ma_dept_config mdc ON mdc.type_id = mtv.typeId AND mdc.dept_id = #{deptId}
GROUP BY
mtv.typeId
UNION ALL
-- 原SQL的第二部分工具4级节点
SELECT
tt.type_id AS equipmentId,
CONCAT_WS('>', tt3.type_name, tt2.type_name, tt1.type_name) AS equipmentName,
tt.type_name AS equipmenttype,
'2' as jijuType,
CASE
WHEN MAX(mdc.config_value) IS NOT NULL AND MAX(mdc.config_value) != '' THEN '已配置'
ELSE '未配置'
END AS configStatus
FROM
tool_type tt
LEFT JOIN ma_dept_config mdc ON mdc.type_id = tt.type_id AND mdc.dept_id = #{deptId}
LEFT JOIN tool_type tt1 ON tt.parent_id = tt1.type_id
LEFT JOIN tool_type tt2 ON tt1.parent_id = tt2.type_id
LEFT JOIN tool_type tt3 ON tt2.parent_id = tt3.type_id
WHERE
tt.LEVEL = 4
GROUP BY
tt.type_id
) t
<!-- 动态筛选条件WHERE + IF -->
<where>
<!-- 筛选equipmentName模糊查询 -->
<if test="equipmentName != null and equipmentName != ''">
AND t.equipmentName LIKE CONCAT('%', #{equipmentName}, '%')
</if>
<!-- 筛选configStatus精确匹配已配置/未配置) -->
<if test="configStatus != null and configStatus != ''">
AND t.configStatus = #{configStatus}
</if>
<!-- 筛选equipmenttype模糊查询也可精确根据业务调整 -->
<if test="equipmenttype != null and equipmenttype != ''">
AND t.equipmenttype LIKE CONCAT('%', #{equipmenttype}, '%')
</if>
<!-- 筛选jijuType精确匹配1/2 -->
<if test="jijuType != null and jijuType != ''">
AND t.jijuType = #{jijuType}
</if>
</where>
</select>
<select id="selectConfigList" resultType="com.bonus.material.equipment.domain.ConfigEntity">
SELECT config_value AS basicConfig,
config_type AS configurationType,
config_rate AS configurationRate,
config_description AS configurationDescription,
is_new AS isNew
FROM ma_dept_config
WHERE dept_id = #{deptId}
AND type_id = #{typeId}
AND jiju_type = #{jijuType}
</select>
<select id="getTree" resultType="com.bonus.material.equipment.domain.DeptTreeSelect">
SELECT
mt.type_id AS id,
mt.type_name AS name
FROM ma_type mt
LEFT JOIN ma_type mt2 ON mt.parent_id = mt2.type_id
LEFT JOIN ma_dept_config mdc ON mdc.type_id = mt.type_id
WHERE mt.level = 3
GROUP BY mt.type_id, mt2.type_name, mt.type_name
</select>
<select id="selectDeptConfigRatePivot" resultType="com.bonus.material.equipment.domain.DeptConfigRateSummary">
SELECT my.type_name AS deptName,
my.type_id AS typeId,
sd.dept_name AS companyName,
grouped.dept_id AS companyId,
grouped.config_type AS configType,
grouped.devType AS devType,
grouped.config_value AS configValue,
if(grouped.config_rate = '/', 0, grouped.config_rate) AS configRate,
IFNULL(order_stat.order_count, 0) AS orderCount,
grouped.isNew AS isNew
FROM (SELECT dept_id,
type_id,
config_type,
jiju_type AS devType,
SUM(config_value) AS config_value,
SUM(if(config_rate = '/', 0, config_rate)) AS config_rate,
is_new AS isNew
FROM ma_dept_config
where jiju_type = 1
GROUP BY dept_id, type_id, config_type) grouped
LEFT JOIN sys_dept sd ON sd.dept_id = grouped.dept_id
LEFT JOIN ma_type my ON my.type_id = grouped.type_id
-- 设备订单数量子查询
LEFT JOIN (SELECT sd.dept_id AS dept_id,
mt.type_id AS parent_type_id,
COUNT(md.num) AS order_count
FROM ma_order_details md
LEFT JOIN ma_order_info moi ON md.order_id = moi.order_id
LEFT JOIN ma_dev_info mdi ON md.ma_id = mdi.ma_id
LEFT JOIN ma_type mt ON mdi.type_id = mt.type_id
LEFT JOIN ma_type mt2 ON mt.parent_id = mt2.type_id
LEFT JOIN sys_dept sd ON moi.buyer_company = sd.dept_id
where devType = 0
GROUP BY sd.dept_id, mt.type_id) order_stat
ON order_stat.dept_id = grouped.dept_id
AND order_stat.parent_type_id = grouped.type_id
UNION
SELECT my.type_name AS deptName,
my.type_id AS typeId,
sd.dept_name AS companyName,
grouped.dept_id AS companyId,
grouped.config_type AS configType,
grouped.devType AS devType,
grouped.config_value AS configValue,
if(grouped.config_rate = '/', 0, grouped.config_rate) AS configRate,
IFNULL(order_stat.order_count, 0) AS orderCount,
grouped.isNew AS isNew
FROM (SELECT dept_id,
type_id,
config_type,
jiju_type AS devType,
SUM(config_value) AS config_value,
SUM(if(config_rate = '/', 0, config_rate)) AS config_rate,
is_new AS isNew
FROM ma_dept_config
where jiju_type = 2
GROUP BY dept_id, type_id, config_type) grouped
LEFT JOIN sys_dept sd ON sd.dept_id = grouped.dept_id
LEFT JOIN tool_type my ON my.type_id = grouped.type_id
-- 设备订单数量子查询
LEFT JOIN (SELECT sd.dept_id AS dept_id,
mt.type_id AS parent_type_id,
COUNT(md.num) AS order_count
FROM ma_order_details md
LEFT JOIN ma_order_info moi ON md.order_id = moi.order_id
LEFT JOIN ma_dev_info mdi ON md.ma_id = mdi.ma_id
LEFT JOIN tool_type mt ON mdi.type_id = mt.type_id
LEFT JOIN tool_type mt2 ON mt.parent_id = mt2.type_id
LEFT JOIN sys_dept sd ON moi.buyer_company = sd.dept_id
where devType = 1
GROUP BY sd.dept_id, mt.type_id) order_stat
ON order_stat.dept_id = grouped.dept_id
AND order_stat.parent_type_id = grouped.type_id;
</select>
<select id="selectDeptConfigTypeSummary" resultType="com.bonus.material.equipment.domain.DeptConfigTypeSummary">
SELECT mt1.type_name AS typeName,
mt2.type_name AS parentTypeName,
CAST(mdc.config_rate AS DECIMAL(10, 2)) AS configRate,
mdc.config_description AS configDescription
FROM ma_dept_config mdc
LEFT JOIN ma_type mt1 ON mt1.type_id = mdc.type_id
LEFT JOIN ma_type mt2 ON mt2.type_id = mt1.parent_id
WHERE mdc.dept_id = #{deptId}
</select>
<select id="detailsInfo" resultType="com.bonus.material.equipment.domain.EquipmentDetail">
SELECT CASE
WHEN mtv.actual_level = 5 THEN
mtv.devSubcategory
WHEN mtv.actual_level = 6 THEN
mtv.devName
ELSE ''
END AS name,
CASE
WHEN mtv.actual_level = 5 THEN
CONCAT_WS('>', mtv.proType, mtv.mainGx, mtv.childGx, mtv.devCategory)
WHEN mtv.actual_level = 6 THEN
CONCAT_WS('>', mtv.proType, mtv.mainGx, mtv.childGx, mtv.devCategory, mtv.devSubcategory)
ELSE CONCAT_WS('>',
mtv.proType, mtv.mainGx, mtv.childGx, mtv.devCategory, mtv.devSubcategory)
END AS combinedName,
COUNT(mdi.ma_id) AS own,
mdc.config_value AS standard,
mdc.config_rate AS value,
CASE
WHEN mdc.config_value = 0 THEN 0
WHEN COUNT(mdi.ma_id) / mdc.config_value &gt;= 1 THEN mdc.config_rate
WHEN COUNT(mdi.ma_id) / mdc.config_value &lt; 1
THEN (COUNT(mdi.ma_id) / mdc.config_value) * mdc.config_rate
ELSE 0
END AS actual,
mdc.config_description AS `desc`,
mdc.is_new AS isNew
FROM ma_dept_config mdc
INNER JOIN ma_type_view mtv ON mtv.typeId = mdc.type_id
AND mdc.jiju_type = '1'
INNER JOIN ma_dev_info mdi ON mdi.type_id = mtv.typeId
AND mdi.is_active = '1'
AND mdi.entry_status = '1'
WHERE mdc.config_type = #{configType}
AND mdc.dept_id = #{companyId}
AND mdc.jiju_type = '1'
GROUP BY mdi.type_id
UNION ALL
SELECT tt.type_name AS name,
CONCAT_WS('>', tt3.type_name, tt2.type_name, tt1.type_name) AS combinedName,
SUM(mdi.total_num - mdi.scrap_num) AS own,
mdc.config_value AS standard,
mdc.config_rate AS value,
CASE
WHEN mdc.config_value = 0 THEN 0
WHEN SUM(mdi.total_num - mdi.scrap_num) / mdc.config_value &gt;= 1 THEN mdc.config_rate
WHEN SUM(mdi.total_num - mdi.scrap_num) / mdc.config_value &lt; 1 THEN
(SUM(mdi.total_num - mdi.scrap_num) / mdc.config_value) * mdc.config_rate
ELSE 0
END AS actual,
mdc.config_description AS `desc`,
mdc.is_new AS isNew
FROM ma_dept_config mdc
INNER JOIN tool_type tt ON tt.type_id = mdc.type_id
INNER JOIN tool_type tt4 ON tt4.parent_id = tt.type_id
INNER JOIN tool_ledger mdi ON mdi.type_id = tt4.type_id
INNER JOIN tool_type tt1 ON tt.parent_id = tt1.type_id
INNER JOIN tool_type tt2 ON tt1.parent_id = tt2.type_id
INNER JOIN tool_type tt3 ON tt2.parent_id = tt3.type_id
WHERE mdc.config_type = #{configType}
AND mdc.dept_id = #{companyId}
AND mdc.jiju_type = '2'
GROUP BY tt.type_id
</select>
<select id="listFromDevInfo" resultType="com.bonus.material.equipment.domain.NewmydevInfo">
SELECT
md.on_company AS companyId,
mt2.type_id AS typeId, mt2.type_name as typeName,
SUM( 1 ) AS ownCount
FROM
ma_dev_info md
LEFT JOIN ma_type mt ON mt.type_id = md.type_id
LEFT JOIN ma_type mt2 on mt.parent_id = mt2.type_id
WHERE
md.is_active = '1' AND md.on_company = #{companyId}
GROUP BY
mt2.type_id
</select>
<select id="getCityName" resultType="java.lang.String">
select name
from sys_cnarea where area_code = #{city}
</select>
</mapper>