314 lines
12 KiB
SQL
314 lines
12 KiB
SQL
-- ============================================
|
||
-- 智能候选池查询SQL(当日已挂号患者)
|
||
-- 对应接口:GET /charge-manage/register/current-day-encounter
|
||
-- 用途:查询当日已挂号但未入队的患者,用于智能分诊排队管理
|
||
-- ============================================
|
||
|
||
-- 完整SQL查询(包含所有关联表)
|
||
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
|
||
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 (
|
||
-- 如果就诊状态为"进行中",查找"接诊医生"(admitter)
|
||
(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
|
||
-- 如果就诊状态不是"进行中",查找"挂号医生"(registration_doctor)
|
||
(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'
|
||
AND T10.context_enum = 1 -- REGISTER(挂号)
|
||
-- 关联账户表(收费账户)
|
||
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(支付成功)
|
||
-- 关联退号记录(当状态为退号时,通过relation_id关联原支付记录)
|
||
LEFT JOIN fin_payment_reconciliation T14
|
||
ON T13.id = T14.relation_id
|
||
AND T14.delete_flag = '0'
|
||
AND T14.status_enum = 3 -- REFUND(退款)
|
||
AND T14.payment_enum = 1
|
||
-- 关联退号医生
|
||
LEFT JOIN adm_practitioner AS T15
|
||
ON T15.ID = T14.enterer_id
|
||
AND T15.delete_flag = '0'
|
||
-- 关联系统用户表
|
||
LEFT JOIN sys_user AS T17
|
||
ON T17.user_id = T15.user_id
|
||
AND T17.delete_flag = '0'
|
||
-- 关联退号支付详情,获取退款方式(聚合多个支付方式)
|
||
LEFT JOIN (
|
||
SELECT reconciliation_id,
|
||
STRING_AGG(
|
||
CASE pay_enum
|
||
WHEN 220400 THEN '现金'
|
||
WHEN 220100 THEN '微信'
|
||
WHEN 220200 THEN '支付宝'
|
||
WHEN 220300 THEN '银联'
|
||
END,
|
||
','
|
||
ORDER BY pay_enum
|
||
) AS refund_method
|
||
FROM fin_payment_rec_detail
|
||
WHERE delete_flag = '0'
|
||
AND amount < 0
|
||
AND pay_enum IN (220400, 220100, 220200, 220300)
|
||
GROUP BY reconciliation_id
|
||
) AS T16 ON T14.id = T16.reconciliation_id
|
||
-- 关联发票表
|
||
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 T10.context_enum = 1 -- 挂号(REGISTER)
|
||
-- 动态条件(由前端传入,通过 ${ew.customSqlSegment} 注入)
|
||
-- 例如:AND T1.create_time::DATE = CURRENT_DATE -- 当日挂号
|
||
-- 例如:AND T1.status_enum != 6 -- 排除退号(statusEnum = -1时)
|
||
-- 例如:AND (T8.name LIKE '%关键词%' OR T2.name LIKE '%关键词%' ...) -- 模糊搜索
|
||
) AS T9
|
||
-- 动态查询条件(由 MyBatis-Plus QueryWrapper 生成)
|
||
-- ${ew.customSqlSegment}
|
||
ORDER BY T9.register_time DESC;
|
||
|
||
-- ============================================
|
||
-- 简化版查询(仅查询核心字段,用于快速测试)
|
||
-- ============================================
|
||
SELECT
|
||
enc.id AS encounterId,
|
||
enc.patient_id AS patientId,
|
||
pt.name AS patientName,
|
||
pt.birth_date AS birthDate,
|
||
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
|
||
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 -- 排除退号
|
||
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 -- 当日挂号(由前端传入 date 参数)
|
||
--
|
||
-- 3. 状态过滤:
|
||
-- - enc.status_enum != 6 -- 排除退号(当 statusEnum = -1 时)
|
||
-- - enc.status_enum = 2 -- 进行中(IN_PROGRESS,用于判断医生类型)
|
||
--
|
||
-- 4. 模糊搜索(由前端传入 searchKey 参数):
|
||
-- - patient_name(患者姓名)
|
||
-- - organization_name(科室名称)
|
||
-- - practitioner_name(医生姓名)
|
||
-- - healthcare_name(号别名称)
|
||
-- - identifier_no(身份证号)
|
||
--
|
||
-- 5. 租户过滤(由后端自动添加):
|
||
-- - tenant_id = ? -- 当前登录用户的租户ID
|
||
--
|
||
-- 6. 分页(由 MyBatis-Plus Page 对象处理):
|
||
-- - LIMIT ? OFFSET ?
|
||
|
||
-- ============================================
|
||
-- 常用查询示例
|
||
-- ============================================
|
||
|
||
-- 示例1:查询今天所有已挂号患者(排除退号)
|
||
SELECT
|
||
enc.id AS encounterId,
|
||
pt.name AS patientName,
|
||
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
|
||
ORDER BY enc.create_time DESC;
|
||
|
||
-- 示例2:查询指定科室的已挂号患者
|
||
-- 在示例1的基础上添加:
|
||
-- AND enc.organization_id = ? -- 科室ID
|
||
|
||
-- 示例3:按患者姓名模糊搜索
|
||
-- 在示例1的基础上添加:
|
||
-- AND pt.name LIKE '%关键词%'
|
||
|
||
-- 示例4:查询已加入队列的患者(用于去重)
|
||
SELECT DISTINCT encounter_id
|
||
FROM hisdev.triage_queue_item
|
||
WHERE delete_flag = '0'
|
||
AND queue_date = CURRENT_DATE
|
||
AND status != 'COMPLETED';
|
||
|