Commit b2781bea authored by tianbo's avatar tianbo

refactor(jg): 优化设备过滤查询性能

- 重构设备过滤查询逻辑,使用预过滤设备列表的方式提高查询效率 - 新增 pre_filtered_equipment CTE进行设备表过滤 - 使用 EXISTS 子查询替代原来的 IN子查询,减少不必要的数据扫描
parent 232e04dc
......@@ -384,10 +384,36 @@
<!-- 情况1:有设备过滤条件 -->
<when test="dto.equList != null or dto.equCategory != null or dto.equDefine != null or
dto.equCode != null or dto.code96333 != null or dto.supervisoryCode != null">
WITH filtered_main_ids AS (
SELECT fu.sequence_nbr
FROM tzs_jg_use_registration fu
WHERE fu.is_delete = '0'
WITH pre_filtered_equipment AS (
SELECT DISTINCT re.equip_transfer_id
FROM tzs_jg_use_registration_eq re
WHERE EXISTS (
SELECT 1 FROM idx_biz_jg_register_info jri,idx_biz_jg_other_info other
WHERE jri."RECORD" = re.equ_id AND other."RECORD" = re.equ_id
<!-- 设备表过滤条件 -->
<if test="dto.equList != null and dto.equList != ''">
AND jri."EQU_LIST" = #{dto.equList}
</if>
<if test="dto.equCategory != null and dto.equCategory != ''">
AND jri."EQU_CATEGORY" = #{dto.equCategory}
</if>
<if test="dto.equDefine != null and dto.equDefine != ''">
AND jri."EQU_DEFINE" = #{dto.equDefine}
</if>
<if test="dto.equCode != null and dto.equCode != ''">
AND jri."EQU_CODE" LIKE CONCAT(#{dto.equCode}, '%')
</if>
<if test="dto.code96333 != null and dto.code96333 != ''">
AND other."CODE96333" LIKE CONCAT(#{dto.code96333}, '%')
</if>
<if test="dto.supervisoryCode != null and dto.supervisoryCode != ''">
AND other."SUPERVISORY_CODE" LIKE CONCAT(#{dto.supervisoryCode}, '%')
</if>
)
AND EXISTS (
SELECT 1 FROM tzs_jg_use_registration fu
WHERE fu.sequence_nbr = re.equip_transfer_id
AND fu.is_delete = '0'
<!-- 公共主表过滤条件 -->
<if test="dto.status != null and dto.status != ''">
AND fu.status = #{dto.status}
......@@ -439,30 +465,72 @@
AND (fu.use_unit_credit_code = #{dto.unitCode}
OR fu.transfer_to_user_ids LIKE CONCAT('%', #{dto.currentUserId}, '%'))
</if>
)
),
main_data AS (
SELECT
fu.sequence_nbr AS sequenceNbr,
fu.audit_status AS auditStatus,
DATE_FORMAT ( fu.reg_date, '%Y-%m-%d' ) AS regDate,
fu.use_unit_name AS useUnitName,
fu.supervision_org_code AS supervisionOrgCode,
fu.status,
fu.receive_org_name AS receiveOrgName,
fu.use_address AS place,
fu.instance_id AS instanceId,
fu.apply_no AS applyNo,
fu.next_execute_ids AS nextExecuteIds,
fu.promoter,
fu.use_registration_code AS useRegistrationCode,
DATE_FORMAT ( fu.audit_pass_date, '%Y-%m-%d' ) AS auditPassDate,
DATE_FORMAT ( fu.create_date, '%Y-%m-%d' ) AS createDate,
fu.receive_org_name AS receiveOrgName,
fu.next_execute_user_ids AS nextExecuteUserIds,
fu.next_task_id AS nextTaskId,
fu.create_user_id AS createUserId,
fu.rec_date AS recDate,
fu.manage_type AS manageType,
fu.reg_type AS regType,
fu.is_delete,
fu.create_date,
fu.receive_company_code,
fu.use_unit_credit_code,
fu.transfer_to_user_ids,
fu.supervision_org_code,
fu.use_address AS fullAddress,
fu.cancel_reason AS cancelReason,
fu.project_contraption_id AS projectContraptionId,
( SELECT company_name FROM privilege_company WHERE org_code = fu.supervision_org_code AND is_deleted = FALSE LIMIT 1 ) AS orgBranchName
FROM pre_filtered_equipment pfe
JOIN tzs_jg_use_registration fu ON pfe.equip_transfer_id = fu.sequence_nbr
ORDER BY fu.create_date DESC, fu.apply_no DESC
LIMIT 20 OFFSET 0
)
SELECT
md.*,
(SELECT STRING_AGG(DISTINCT other.code96333, ',')
FROM tzs_jg_use_registration_eq re
JOIN idx_biz_jg_register_info jri ON re.equ_id = jri."RECORD"
JOIN idx_biz_jg_other_info other ON jri."RECORD" = other."RECORD"
WHERE re.equip_transfer_id = md.sequenceNbr) AS code96333,
(SELECT STRING_AGG(DISTINCT other.supervisory_code, ',')
FROM tzs_jg_use_registration_eq re
JOIN idx_biz_jg_register_info jri ON re.equ_id = jri."RECORD"
JOIN idx_biz_jg_other_info other ON jri."RECORD" = other."RECORD"
WHERE re.equip_transfer_id = md.sequenceNbr) AS supervisoryCode
FROM main_data md
WITH filtered_main_ids AS (
SELECT fu.sequence_nbr
FROM tzs_jg_use_registration fu
WHERE fu.is_delete = '0'
AND exists(
SELECT 1 FROM tzs_jg_use_registration_eq re
INNER JOIN idx_biz_jg_register_info jri ON re.equ_id = jri."RECORD"
LEFT JOIN idx_biz_jg_other_info other ON jri."RECORD" = other."RECORD"
WHERE re.equip_transfer_id = fu.sequence_nbr
<!-- 设备表过滤条件 -->
<if test="dto.equList != null and dto.equList != ''">
AND jri."EQU_LIST" = #{dto.equList}
</if>
<if test="dto.equCategory != null and dto.equCategory != ''">
AND jri."EQU_CATEGORY" = #{dto.equCategory}
</if>
<if test="dto.equDefine != null and dto.equDefine != ''">
AND jri."EQU_DEFINE" = #{dto.equDefine}
</if>
<if test="dto.equCode != null and dto.equCode != ''">
AND jri."EQU_CODE" LIKE CONCAT(#{dto.equCode}, '%')
</if>
<if test="dto.code96333 != null and dto.code96333 != ''">
AND other."CODE96333" LIKE CONCAT(#{dto.code96333}, '%')
</if>
<if test="dto.supervisoryCode != null and dto.supervisoryCode != ''">
AND other."SUPERVISORY_CODE" LIKE CONCAT(#{dto.supervisoryCode}, '%')
</if>
)
)
SELECT
......@@ -499,17 +567,17 @@
fu.project_contraption_id AS projectContraptionId,
(select company_name from privilege_company where org_code = fu.supervision_org_code and is_deleted = false limit 1) AS orgBranchName,
COALESCE(STRING_AGG(DISTINCT re.equ_id), '') AS equipId,
COALESCE(STRING_AGG(DISTINCT other.supervisory_code), '') AS supervisoryCode,
COALESCE(STRING_AGG(DISTINCT other.CODE96333), '') AS code96333,
COALESCE(STRING_AGG(DISTINCT jri.PRODUCT_NAME), '') AS productName,
COALESCE(STRING_AGG(DISTINCT jri.EQU_CODE), '') AS equCode,
COALESCE(STRING_AGG(DISTINCT jri.EQU_LIST), '') AS equListCode,
COALESCE(STRING_AGG(DISTINCT jri.EQU_CATEGORY), '') AS equCategoryCode,
COALESCE(STRING_AGG(DISTINCT jri.EQU_DEFINE), '') AS equDefineCode,
COALESCE(STRING_AGG(DISTINCT c_list.name), '') AS equListName,
COALESCE(STRING_AGG(DISTINCT c_cate.name), '') AS equCategory,
COALESCE(STRING_AGG(DISTINCT c_def.name), '') AS equDefine
COALESCE(STRING_AGG(DISTINCT re.equ_id, ','), '') AS equipId,
COALESCE(STRING_AGG(DISTINCT other.supervisory_code, ','), '') AS supervisoryCode,
COALESCE(STRING_AGG(DISTINCT other.CODE96333, ','), '') AS code96333,
COALESCE(STRING_AGG(DISTINCT jri.PRODUCT_NAME, ','), '') AS productName,
COALESCE(STRING_AGG(DISTINCT jri.EQU_CODE, ','), '') AS equCode,
COALESCE(STRING_AGG(DISTINCT jri.EQU_LIST, ','), '') AS equListCode,
COALESCE(STRING_AGG(DISTINCT jri.EQU_CATEGORY, ','), '') AS equCategoryCode,
COALESCE(STRING_AGG(DISTINCT jri.EQU_DEFINE, ','), '') AS equDefineCode,
COALESCE(STRING_AGG(DISTINCT c_list.name, ','), '') AS equListName,
COALESCE(STRING_AGG(DISTINCT c_cate.name, ','), '') AS equCategory,
COALESCE(STRING_AGG(DISTINCT c_def.name, ','), '') AS equDefine
FROM filtered_main_ids fm
JOIN tzs_jg_use_registration fu ON fm.sequence_nbr = fu.sequence_nbr
......
Markdown is supported
0% or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment