Files
his/openhis-server-new/sql/query_smart_candidate_pool_with_exclusion.sql

367 lines
15 KiB
SQL
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.

-- ============================================
-- 智能候选池查询SQL完整版 - 包含排除列表)
-- 页面:智能分诊排队管理 - 心内科
-- 用途:查询"已签到未入队"的患者(当日已挂号,但未加入队列,且未在排除列表中)
-- 更新日期2025-01-15
-- ============================================
-- ============================================
-- 方案一:完整查询(包含所有字段,排除已在队列和排除列表中的患者)
-- ============================================
SELECT
T9.tenant_id AS tenantId,
T9.encounter_id AS encounterId,
T9.display_order AS displayOrder,
T9.organization_id AS organizationId,
T9.organization_name AS organizationName,
T9.healthcare_name AS healthcareName,
T9.practitioner_user_id AS practitionerUserId,
T9.practitioner_name AS practitionerName,
T9.contract_name AS contractName,
T9.patient_id AS patientId,
T9.patient_name AS patientName,
T9.phone,
T9.gender_enum AS genderEnum,
T9.id_card AS idCard,
T9.status_enum AS statusEnum,
T9.register_time AS registerTime,
T9.total_price AS totalPrice,
T9.account_name AS accountName,
T9.enterer_name AS entererName,
T9.charge_item_ids AS chargeItemIds,
T9.payment_id AS paymentId,
T9.picture_url AS pictureUrl,
T9.birth_date AS birthDate,
COALESCE(T9.identifier_no, T9.patient_bus_no, '') AS identifierNo,
-- 计算年龄(前端会调用 parseAge 函数)
CASE
WHEN T9.birth_date IS NOT NULL THEN
EXTRACT(YEAR FROM AGE(T9.birth_date))::TEXT || ''
ELSE ''
END AS age
FROM (
SELECT T1.tenant_id AS tenant_id,
T1.id AS encounter_id,
T1.display_order AS display_order,
T1.organization_id AS organization_id,
T2.NAME AS organization_name,
T3.NAME AS healthcare_name,
T5.user_id AS practitioner_user_id,
T5.NAME AS practitioner_name,
T7.contract_name AS contract_name,
T8.id AS patient_id,
T8.NAME AS patient_name,
T8.phone AS phone,
T8.gender_enum AS gender_enum,
T8.id_card AS id_card,
T1.status_enum AS status_enum,
T1.create_time AS register_time,
T10.total_price,
T11."name" AS account_name,
T12."name" AS enterer_name,
T13.charge_item_ids,
T13.id AS payment_id,
ai.picture_url AS picture_url,
T8.birth_date AS birth_date,
T8.bus_no AS patient_bus_no,
T18.identifier_no AS identifier_no
FROM adm_encounter AS T1
LEFT JOIN adm_organization AS T2 ON T1.organization_id = T2.ID AND T2.delete_flag = '0'
LEFT JOIN adm_healthcare_service AS T3 ON T1.service_type_id = T3.ID AND T3.delete_flag = '0'
LEFT JOIN (
SELECT *
FROM (
SELECT *,
ROW_NUMBER() OVER (PARTITION BY encounter_id ORDER BY create_time ASC) AS rn
FROM adm_encounter_participant
WHERE delete_flag = '0'
AND (
(type_code = 'admitter' AND EXISTS(SELECT 1
FROM adm_encounter AS T1
WHERE T1.status_enum = 2 -- IN_PROGRESS
AND T1.ID = encounter_id))
OR
(type_code = 'registration_doctor' AND NOT EXISTS(SELECT 1
FROM adm_encounter AS T1
WHERE T1.status_enum = 2 -- IN_PROGRESS
AND T1.ID = encounter_id))
)
) t
WHERE rn = 1
) AS T4 ON T1.ID = T4.encounter_id
LEFT JOIN adm_practitioner AS T5 ON T5.ID = T4.practitioner_id AND T5.delete_flag = '0'
LEFT JOIN adm_account AS T6
ON T1.ID = T6.encounter_id AND T6.delete_flag = '0' AND T6.encounter_flag = '1'
LEFT JOIN fin_contract AS T7 ON T6.contract_no = T7.bus_no AND T7.delete_flag = '0'
LEFT JOIN adm_patient AS T8 ON T1.patient_id = T8.ID AND T8.delete_flag = '0'
LEFT JOIN (
SELECT patient_id,
identifier_no
FROM (
SELECT patient_id,
identifier_no,
ROW_NUMBER() OVER (PARTITION BY patient_id ORDER BY create_time ASC) AS rn
FROM adm_patient_identifier
WHERE delete_flag = '0'
AND identifier_no IS NOT NULL
AND identifier_no != ''
) t
WHERE rn = 1
) AS T18 ON T8.id = T18.patient_id
LEFT JOIN adm_charge_item AS T10 ON T1.id = T10.encounter_id AND T10.delete_flag = '0'
LEFT JOIN adm_account AS T11 ON T10.account_id = T11.id AND T11.delete_flag = '0'
LEFT JOIN adm_practitioner AS T12 ON T12.ID = T10.enterer_id AND T12.delete_flag = '0'
LEFT JOIN fin_payment_reconciliation T13
ON T10.id::TEXT = ANY(string_to_array(T13.charge_item_ids,','))
AND T13.delete_flag = '0'
AND T13.status_enum = 1 -- SUCCESS支付成功
LEFT JOIN adm_invoice AS ai
ON ai.reconciliation_id = T13.id AND ai.delete_flag = '0'
WHERE T1.delete_flag = '0'
AND T1.class_enum = 1 -- 门诊AMB
AND T1.create_time::DATE = CURRENT_DATE -- 当日挂号
AND T1.status_enum != 6 -- 排除退号
AND T10.context_enum = 1 -- REGISTER挂号
) AS T9
-- 排除已在队列中的患者关键LEFT JOIN + WHERE IS NULL
LEFT JOIN hisdev.triage_queue_item tqi
ON T9.encounter_id = tqi.encounter_id
AND tqi.delete_flag = '0'
AND tqi.queue_date = CURRENT_DATE
AND tqi.status != 'COMPLETED' -- 排除已完成的状态
-- 排除已在排除列表中的患者新增关键LEFT JOIN + WHERE IS NULL
LEFT JOIN hisdev.triage_candidate_exclusion tce
ON T9.encounter_id = tce.encounter_id
AND tce.delete_flag = '0'
AND tce.exclusion_date = CURRENT_DATE
AND tce.tenant_id = T9.tenant_id -- 按租户过滤
WHERE tqi.id IS NULL -- 关键:只查询不在队列中的患者
AND tce.id IS NULL -- 关键:只查询不在排除列表中的患者
ORDER BY T9.register_time DESC;
-- ============================================
-- 方案二:简化查询(仅核心字段,便于快速测试)
-- ============================================
SELECT
enc.id AS encounterId,
enc.patient_id AS patientId,
pt.name AS patientName,
org.id AS organizationId,
org.name AS organizationName,
hcs.name AS healthcareName,
pr.name AS practitionerName,
enc.create_time AS registerTime
FROM adm_encounter enc
INNER JOIN adm_patient pt ON enc.patient_id = pt.id AND pt.delete_flag = '0'
LEFT JOIN adm_organization org ON enc.organization_id = org.id AND org.delete_flag = '0'
LEFT JOIN adm_healthcare_service hcs ON enc.service_type_id = hcs.id AND hcs.delete_flag = '0'
LEFT JOIN (
SELECT encounter_id, practitioner_id,
ROW_NUMBER() OVER (PARTITION BY encounter_id ORDER BY create_time ASC) AS rn
FROM adm_encounter_participant
WHERE delete_flag = '0' AND type_code IN ('admitter', 'registration_doctor')
) ep ON enc.id = ep.encounter_id AND ep.rn = 1
LEFT JOIN adm_practitioner pr ON ep.practitioner_id = pr.id AND pr.delete_flag = '0'
INNER JOIN adm_charge_item ci ON enc.id = ci.encounter_id AND ci.delete_flag = '0' AND ci.context_enum = 1
INNER JOIN fin_payment_reconciliation prc ON ci.id::TEXT = ANY(string_to_array(prc.charge_item_ids,','))
AND prc.delete_flag = '0' AND prc.status_enum = 1
-- 排除已在队列中的患者
LEFT JOIN hisdev.triage_queue_item tqi
ON enc.id = tqi.encounter_id
AND tqi.delete_flag = '0'
AND tqi.queue_date = CURRENT_DATE
AND tqi.status != 'COMPLETED'
-- 排除已在排除列表中的患者(新增)
LEFT JOIN hisdev.triage_candidate_exclusion tce
ON enc.id = tce.encounter_id
AND tce.delete_flag = '0'
AND tce.exclusion_date = CURRENT_DATE
AND tce.tenant_id = enc.tenant_id
WHERE enc.delete_flag = '0'
AND enc.class_enum = 1
AND enc.create_time::DATE = CURRENT_DATE
AND enc.status_enum != 6
AND tqi.id IS NULL -- 不在队列中
AND tce.id IS NULL -- 不在排除列表中
ORDER BY enc.create_time DESC;
-- ============================================
-- 方案三:使用 NOT EXISTS 子查询(性能可能更好)
-- ============================================
SELECT
enc.id AS encounterId,
enc.patient_id AS patientId,
pt.name AS patientName,
org.id AS organizationId,
org.name AS organizationName,
hcs.name AS healthcareName,
pr.name AS practitionerName,
enc.create_time AS registerTime
FROM adm_encounter enc
INNER JOIN adm_patient pt ON enc.patient_id = pt.id AND pt.delete_flag = '0'
LEFT JOIN adm_organization org ON enc.organization_id = org.id AND org.delete_flag = '0'
LEFT JOIN adm_healthcare_service hcs ON enc.service_type_id = hcs.id AND hcs.delete_flag = '0'
LEFT JOIN (
SELECT encounter_id, practitioner_id,
ROW_NUMBER() OVER (PARTITION BY encounter_id ORDER BY create_time ASC) AS rn
FROM adm_encounter_participant
WHERE delete_flag = '0' AND type_code IN ('admitter', 'registration_doctor')
) ep ON enc.id = ep.encounter_id AND ep.rn = 1
LEFT JOIN adm_practitioner pr ON ep.practitioner_id = pr.id AND pr.delete_flag = '0'
INNER JOIN adm_charge_item ci ON enc.id = ci.encounter_id AND ci.delete_flag = '0' AND ci.context_enum = 1
INNER JOIN fin_payment_reconciliation prc ON ci.id::TEXT = ANY(string_to_array(prc.charge_item_ids,','))
AND prc.delete_flag = '0' AND prc.status_enum = 1
WHERE enc.delete_flag = '0'
AND enc.class_enum = 1
AND enc.create_time::DATE = CURRENT_DATE
AND enc.status_enum != 6
-- 排除已在队列中的患者
AND NOT EXISTS (
SELECT 1
FROM hisdev.triage_queue_item tqi
WHERE tqi.encounter_id = enc.id
AND tqi.delete_flag = '0'
AND tqi.queue_date = CURRENT_DATE
AND tqi.status != 'COMPLETED'
)
-- 排除已在排除列表中的患者(新增)
AND NOT EXISTS (
SELECT 1
FROM hisdev.triage_candidate_exclusion tce
WHERE tce.encounter_id = enc.id
AND tce.delete_flag = '0'
AND tce.exclusion_date = CURRENT_DATE
AND tce.tenant_id = enc.tenant_id
)
ORDER BY enc.create_time DESC;
-- ============================================
-- 查询条件说明
-- ============================================
-- 1. 基础条件:
-- - enc.delete_flag = '0' -- 未删除
-- - enc.class_enum = 1 -- 门诊AMB
-- - ci.context_enum = 1 -- 挂号REGISTER
-- - prc.status_enum = 1 -- 支付成功SUCCESS
--
-- 2. 日期过滤:
-- - enc.create_time::DATE = CURRENT_DATE -- 当日挂号
-- 注意:前端还会基于 registerTime 字段再次过滤今天的数据
--
-- 3. 状态过滤:
-- - enc.status_enum != 6 -- 排除退号(对应前端 statusEnum = -1
--
-- 4. 队列去重:
-- - LEFT JOIN hisdev.triage_queue_item ... WHERE tqi.id IS NULL
-- 或者
-- - NOT EXISTS (SELECT 1 FROM hisdev.triage_queue_item ...)
-- 排除已在队列中且状态不是 COMPLETED 的患者
--
-- 5. 排除列表去重(新增):
-- - LEFT JOIN hisdev.triage_candidate_exclusion ... WHERE tce.id IS NULL
-- 或者
-- - NOT EXISTS (SELECT 1 FROM hisdev.triage_candidate_exclusion ...)
-- 排除已在排除列表中的患者(已加入队列后被记录)
--
-- 6. 租户过滤(如果需要):
-- - enc.tenant_id = ? -- 当前登录用户的租户ID
--
-- 7. 模糊搜索(如果需要):
-- - pt.name LIKE '%关键词%' -- 患者姓名
-- - org.name LIKE '%关键词%' -- 科室名称
-- - pr.name LIKE '%关键词%' -- 医生姓名
-- - hcs.name LIKE '%关键词%' -- 号别名称
-- ============================================
-- 调试查询(检查数据是否正确)
-- ============================================
-- 1. 检查当日已挂号患者总数
SELECT COUNT(*) AS total_registered
FROM adm_encounter enc
INNER JOIN adm_charge_item ci ON enc.id = ci.encounter_id AND ci.delete_flag = '0' AND ci.context_enum = 1
INNER JOIN fin_payment_reconciliation prc ON ci.id::TEXT = ANY(string_to_array(prc.charge_item_ids,','))
AND prc.delete_flag = '0' AND prc.status_enum = 1
WHERE enc.delete_flag = '0'
AND enc.class_enum = 1
AND enc.create_time::DATE = CURRENT_DATE
AND enc.status_enum != 6;
-- 2. 检查已在队列中的患者数量
SELECT COUNT(DISTINCT encounter_id) AS in_queue_count
FROM hisdev.triage_queue_item
WHERE delete_flag = '0'
AND queue_date = CURRENT_DATE
AND status != 'COMPLETED';
-- 3. 检查已在排除列表中的患者数量(新增)
SELECT COUNT(DISTINCT encounter_id) AS in_exclusion_count
FROM hisdev.triage_candidate_exclusion
WHERE delete_flag = '0'
AND exclusion_date = CURRENT_DATE;
-- 4. 检查候选池应该显示的患者数量(已挂号 - 已在队列 - 已在排除列表)
SELECT
(SELECT COUNT(*)
FROM adm_encounter enc
INNER JOIN adm_charge_item ci ON enc.id = ci.encounter_id AND ci.delete_flag = '0' AND ci.context_enum = 1
INNER JOIN fin_payment_reconciliation prc ON ci.id::TEXT = ANY(string_to_array(prc.charge_item_ids,','))
AND prc.delete_flag = '0' AND prc.status_enum = 1
WHERE enc.delete_flag = '0'
AND enc.class_enum = 1
AND enc.create_time::DATE = CURRENT_DATE
AND enc.status_enum != 6)
-
(SELECT COUNT(DISTINCT encounter_id)
FROM hisdev.triage_queue_item
WHERE delete_flag = '0'
AND queue_date = CURRENT_DATE
AND status != 'COMPLETED')
-
(SELECT COUNT(DISTINCT encounter_id)
FROM hisdev.triage_candidate_exclusion
WHERE delete_flag = '0'
AND exclusion_date = CURRENT_DATE)
AS candidate_pool_count;
-- 5. 查看队列中的患者详情(用于对比)
SELECT
tqi.encounter_id,
tqi.patient_name,
tqi.status,
tqi.queue_order
FROM hisdev.triage_queue_item tqi
WHERE tqi.delete_flag = '0'
AND tqi.queue_date = CURRENT_DATE
AND tqi.status != 'COMPLETED'
ORDER BY tqi.queue_order;
-- 6. 查看排除列表中的患者详情(新增)
SELECT
tce.encounter_id,
tce.patient_name,
tce.reason,
tce.create_time
FROM hisdev.triage_candidate_exclusion tce
WHERE tce.delete_flag = '0'
AND tce.exclusion_date = CURRENT_DATE
ORDER BY tce.create_time DESC;
-- 7. 查看重叠的患者(既在队列中,又在排除列表中)
SELECT
tqi.encounter_id,
tqi.patient_name AS queue_patient_name,
tce.patient_name AS exclusion_patient_name,
tqi.status,
tce.reason
FROM hisdev.triage_queue_item tqi
INNER JOIN hisdev.triage_candidate_exclusion tce
ON tqi.encounter_id = tce.encounter_id
AND tqi.queue_date = tce.exclusion_date
AND tqi.tenant_id = tce.tenant_id
WHERE tqi.delete_flag = '0'
AND tce.delete_flag = '0'
AND tqi.queue_date = CURRENT_DATE
ORDER BY tqi.encounter_id;