挂号补单功能的完善
This commit is contained in:
268
openhis-server-new/sql/query_smart_candidate_pool_page.sql
Normal file
268
openhis-server-new/sql/query_smart_candidate_pool_page.sql
Normal file
@@ -0,0 +1,268 @@
|
||||
-- ============================================
|
||||
-- 智能候选池查询SQL(智能分诊排队管理页面专用)
|
||||
-- 页面:智能分诊排队管理 - 心内科
|
||||
-- 用途:查询"已签到未入队"的患者(当日已挂号,但未加入队列)
|
||||
-- ============================================
|
||||
|
||||
-- ============================================
|
||||
-- 方案一:完整查询(包含所有字段,排除已在队列中的患者)
|
||||
-- ============================================
|
||||
SELECT
|
||||
enc.id AS encounterId,
|
||||
enc.patient_id AS patientId,
|
||||
pt.name AS patientName,
|
||||
pt.birth_date AS birthDate,
|
||||
-- 计算年龄(前端会调用 parseAge 函数)
|
||||
CASE
|
||||
WHEN pt.birth_date IS NOT NULL THEN
|
||||
EXTRACT(YEAR FROM AGE(pt.birth_date))::TEXT || '岁'
|
||||
ELSE ''
|
||||
END AS age,
|
||||
org.id AS organizationId,
|
||||
org.name AS organizationName,
|
||||
hcs.name AS healthcareName,
|
||||
pr.name AS practitionerName,
|
||||
enc.create_time AS registerTime,
|
||||
enc.status_enum AS statusEnum,
|
||||
-- 其他字段(如果需要)
|
||||
pt.phone,
|
||||
pt.gender_enum AS genderEnum,
|
||||
pt.id_card AS idCard
|
||||
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 (
|
||||
-- 如果就诊状态为"进行中",查找"接诊医生"(admitter)
|
||||
(type_code = 'admitter' AND EXISTS(SELECT 1
|
||||
FROM adm_encounter AS e
|
||||
WHERE e.status_enum = 2 -- IN_PROGRESS
|
||||
AND e.id = encounter_id))
|
||||
OR
|
||||
-- 如果就诊状态不是"进行中",查找"挂号医生"(registration_doctor)
|
||||
(type_code = 'registration_doctor' AND NOT EXISTS(SELECT 1
|
||||
FROM adm_encounter AS e
|
||||
WHERE e.status_enum = 2 -- IN_PROGRESS
|
||||
AND e.id = encounter_id))
|
||||
)
|
||||
) 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 -- REGISTER(挂号)
|
||||
-- 关联支付对账表(已支付)
|
||||
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 -- SUCCESS(支付成功)
|
||||
-- 排除已在队列中的患者(关键:LEFT JOIN + WHERE IS NULL)
|
||||
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' -- 排除已完成的状态
|
||||
WHERE enc.delete_flag = '0'
|
||||
AND enc.class_enum = 1 -- 门诊(AMB)
|
||||
AND enc.create_time::DATE = CURRENT_DATE -- 当日挂号(前端会过滤 registerTime)
|
||||
AND enc.status_enum != 6 -- 排除退号(statusEnum = -1 时)
|
||||
AND tqi.id IS NULL -- 关键:只查询不在队列中的患者
|
||||
ORDER BY enc.create_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'
|
||||
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 -- 不在队列中
|
||||
ORDER BY enc.create_time DESC;
|
||||
|
||||
-- ============================================
|
||||
-- 方案三:分步查询(便于调试和理解)
|
||||
-- ============================================
|
||||
|
||||
-- 步骤1:查询当日已挂号的患者(不排除队列)
|
||||
SELECT
|
||||
enc.id AS encounterId,
|
||||
pt.name AS patientName,
|
||||
org.name AS organizationName,
|
||||
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'
|
||||
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 DISTINCT encounter_id
|
||||
FROM hisdev.triage_queue_item
|
||||
WHERE delete_flag = '0'
|
||||
AND queue_date = CURRENT_DATE
|
||||
AND status != 'COMPLETED';
|
||||
|
||||
-- 步骤3:合并查询(使用 NOT EXISTS 或 NOT IN)
|
||||
SELECT
|
||||
enc.id AS encounterId,
|
||||
pt.name AS patientName,
|
||||
org.name AS organizationName,
|
||||
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'
|
||||
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'
|
||||
)
|
||||
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. 租户过滤(如果需要):
|
||||
-- - enc.tenant_id = ? -- 当前登录用户的租户ID
|
||||
--
|
||||
-- 6. 模糊搜索(如果需要):
|
||||
-- - 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
|
||||
(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')
|
||||
AS candidate_pool_count;
|
||||
|
||||
-- 4. 查看队列中的患者详情(用于对比)
|
||||
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;
|
||||
|
||||
Reference in New Issue
Block a user