<?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.jeecg.modules.dnc.mapper.PermissionStreamNewMapper">
|
<select id="loadProductMix" resultType="org.jeecg.modules.dnc.entity.ProductMix">
|
SELECT DISTINCT
|
mix.id,
|
mix.tree_code 'code',
|
mix.tree_name 'name',
|
mix.parent_id,
|
mix.tree_type AS 'type',
|
mix.extend,
|
mix.create_time
|
FROM
|
nc_product_mix mix -- 连接权限表,筛选部门相关记录
|
LEFT JOIN nc_permission_stream_new nps_depart ON mix.id = nps_depart.business_id
|
AND nps_depart.delete_flag = '0'
|
<if test="productIdList != null and productIdList.size() > 0">
|
AND nps_depart.depart_id IN
|
<foreach collection="productIdList" item="productId" index="index" open="(" close=")" separator=",">
|
#{productId}
|
</foreach>
|
</if>
|
AND nps_depart.user_id IS NULL -- 连接权限表,筛选用户相关记录
|
LEFT JOIN nc_permission_stream_new nps_user ON mix.id = nps_user.business_id
|
AND nps_user.user_id = #{userId}
|
AND nps_user.delete_flag = '0'
|
WHERE
|
nps_depart.business_id IS NOT NULL
|
AND nps_user.business_id IS NOT NULL
|
order by mix.tree_type, mix.create_time asc
|
</select>
|
<select id="loadProductMixAll" resultType="org.jeecg.modules.dnc.entity.ProductMix">
|
SELECT DISTINCT mix.id,
|
mix.tree_code 'code',
|
mix.tree_name 'name',
|
mix.parent_id,
|
mix.tree_type AS 'type',
|
mix.extend,
|
mix.create_time
|
FROM nc_product_mix mix -- 连接权限表,筛选部门相关记录
|
LEFT JOIN nc_permission_stream_new nps_user ON mix.id = nps_user.business_id
|
AND nps_user.user_id = #{userId}
|
AND nps_user.delete_flag = '0'
|
WHERE nps_user.business_id IS NOT NULL
|
order by mix.tree_type, mix.create_time asc
|
</select>
|
<select id="loadProductMixByBusinessId" resultType="org.jeecg.modules.dnc.entity.ProductMix">
|
WITH CTE_Hierarchy AS (
|
SELECT
|
CAST(id AS VARCHAR(36)) AS id,
|
CAST(parent_id AS VARCHAR(36)) AS parent_id,
|
1 AS LEVEL,
|
CAST('#' + id + '#' AS VARCHAR(MAX)) AS visit_path
|
FROM
|
nc_product_mix
|
WHERE
|
id = #{businessId}
|
AND tree_type = #{businessType}
|
UNION ALL
|
-- 向上递归父节点(带循环检测)
|
SELECT
|
CAST(p.id AS VARCHAR(36)),
|
CAST(p.parent_id AS VARCHAR(36)),
|
h.level + 1,
|
CAST(h.visit_path + '#' + p.id + '#' AS VARCHAR(MAX))
|
FROM
|
nc_product_mix p
|
INNER JOIN CTE_Hierarchy h ON CAST(p.id AS VARCHAR(36)) = h.parent_id
|
WHERE
|
p.tree_type = #{businessType}
|
AND h.visit_path NOT LIKE '%#' + p.id + '#%'
|
AND h.level < 1000
|
UNION ALL
|
-- 向下递归子节点(带循环检测)
|
SELECT
|
CAST(c.id AS VARCHAR(36)),
|
CAST(c.parent_id AS VARCHAR(36)),
|
h.level + 1,
|
CAST(h.visit_path + '#' + c.id + '#' AS VARCHAR(MAX))
|
FROM
|
nc_product_mix c
|
INNER JOIN CTE_Hierarchy h ON CAST(c.parent_id AS VARCHAR(36)) = h.id
|
WHERE
|
c.tree_type = #{businessType}
|
AND h.visit_path NOT LIKE '%#' + c.id + '#%'
|
AND h.level < 1000
|
),
|
ExclusionCTE AS (
|
SELECT DISTINCT id
|
FROM CTE_Hierarchy
|
WHERE LEVEL BETWEEN 1 AND 1000
|
)
|
SELECT DISTINCT
|
mix.id,
|
mix.tree_code 'code',
|
mix.tree_name 'name',
|
mix.parent_id,
|
mix.tree_type AS 'type',
|
mix.extend,
|
mix.create_time
|
FROM
|
nc_product_mix mix
|
LEFT JOIN nc_permission_stream_new nps_depart ON mix.id = nps_depart.business_id
|
AND nps_depart.delete_flag = '0'
|
<if test="productIdList != null and productIdList.size() > 0">
|
AND nps_depart.depart_id IN
|
<foreach collection="productIdList" item="productId" index="index" open="(" close=")" separator=",">
|
#{productId}
|
</foreach>
|
</if>
|
AND nps_depart.user_id IS NULL
|
LEFT JOIN nc_permission_stream_new nps_user ON mix.id = nps_user.business_id
|
AND nps_user.user_id = #{userId}
|
AND nps_user.delete_flag = '0'
|
WHERE
|
nps_depart.business_id IS NOT NULL
|
AND nps_user.business_id IS NOT NULL
|
AND mix.tree_type = #{businessType}
|
AND NOT EXISTS (SELECT 1 FROM ExclusionCTE e WHERE e.id = mix.id)
|
ORDER BY
|
mix.tree_type,
|
mix.create_time ASC
|
OPTION (MAXRECURSION 0);
|
</select>
|
</mapper>
|