Files
his/openhis-server-new/openhis-application/src/main/resources/mapper/regdoctorstation/AdviceManageAppMapper.xml
chenqi a0b546266d fix(mapper): 修复患者主信息查询的重复数据问题
- 在 getRegPatientMainInfo 查询中添加 DISTINCT ON 子句按 patient_id 去重
- 为分页功能添加 getRegPatientMainInfoCount 计数查询
- 修复 SQL 拼接条件的语法错误,将 ${ew.customSqlSegment} 替换为标准的动态 SQL 标签
- 调整字典标签查询逻辑,先查询指定表再回退到默认字典缓存
- 优化查询性能,避免不必要的数据重复和错误的 SQL 语法
- 添加缺失的 ORDER BY 子句确保查询结果的一致性
2026-01-21 16:22:05 +08:00

367 lines
20 KiB
XML
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.

<?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="com.openhis.web.regdoctorstation.mapper.AdviceManageAppMapper">
<select id="getRegPatientMainInfo" resultType="com.openhis.web.regdoctorstation.dto.RegPatientMainInfoDto">
SELECT DISTINCT ON (rpmi.patient_id)
rpmi.tenant_id,
rpmi.encounter_id,
rpmi.status_enum,
rpmi.bus_no,
rpmi.in_hospital_time,
rpmi.in_hospital_days,
rpmi.out_hospital_time,
rpmi.patient_id,
rpmi.patient_name,
rpmi.gender_enum,
rpmi.birth_date,
rpmi.ward_name,
rpmi.house_name,
rpmi.bed_name,
rpmi.in_org_time,
rpmi.in_hospital_org_id,
rpmi.in_hospital_org_name,
rpmi.contract_no,
rpmi.contract_name,
rpmi.reg_diagnosis_name,
rpmi.account_id
FROM (SELECT ae.tenant_id,
ae.ID AS encounter_id,
ae.status_enum AS status_enum,
ae.bus_no AS bus_no,
ae.start_time AS in_hospital_time,
(EXTRACT(DAY FROM (CURRENT_DATE - ae.start_time)) :: INTEGER + 1) AS in_hospital_days,
ae.end_time AS out_hospital_time,
ap.ID AS patient_id,
ap.NAME AS patient_name,
ap.gender_enum AS gender_enum,
ap.birth_date AS birth_date,
alw.NAME AS ward_name,
alh.NAME AS house_name,
alb.NAME AS bed_name,
aelb.start_time AS in_org_time,
ao.id AS in_hospital_org_id,
ao.NAME AS in_hospital_org_name,
aa.id AS account_id,
aa.contract_no AS contract_no,
fc.contract_name AS contract_name,
ccd.NAME AS reg_diagnosis_name
FROM adm_encounter AS ae
LEFT JOIN adm_patient AS ap ON ap.ID = ae.patient_id
AND ap.delete_flag = '0'
LEFT JOIN adm_organization AS ao ON ao.ID = ae.organization_id
AND ao.delete_flag = '0'
LEFT JOIN adm_encounter_location AS aelw ON aelw.encounter_id = ae.ID
AND aelw.delete_flag = '0'
AND aelw.form_enum = #{wardEnum}
AND aelw.status_enum = #{encounterActivityStatus}
LEFT JOIN adm_location AS alw ON alw.ID = aelw.location_id
AND alw.delete_flag = '0'
LEFT JOIN adm_encounter_location AS aelh ON aelh.encounter_id = ae.ID
AND aelh.delete_flag = '0'
AND aelh.form_enum = #{houseEnum}
AND aelh.status_enum = #{encounterActivityStatus}
LEFT JOIN adm_location AS alh ON alh.ID = aelh.location_id
AND alh.delete_flag = '0'
LEFT JOIN adm_encounter_location AS aelb ON aelb.encounter_id = ae.ID
AND aelb.delete_flag = '0'
AND aelb.form_enum = #{bedEnum}
AND aelb.status_enum = #{encounterActivityStatus}
LEFT JOIN adm_location AS alb ON alb.ID = aelb.location_id
AND alb.delete_flag = '0'
INNER JOIN adm_account AS aa ON aa.encounter_id = ae.ID
AND aa.delete_flag = '0'
AND aa.encounter_flag = 1
LEFT JOIN fin_contract AS fc ON fc.bus_no = aa.contract_no
AND fc.delete_flag = '0'
LEFT JOIN adm_encounter_diagnosis AS aed ON aed.encounter_id = ae.ID
AND aed.delete_flag = '0'
AND aed.maindise_flag = #{maindiseFlag}
LEFT JOIN cli_condition AS cc ON cc.ID = aed.condition_id
AND cc.delete_flag = '0'
LEFT JOIN cli_condition_definition AS ccd ON ccd.ID = cc.definition_id
AND ccd.delete_flag = '0'
WHERE ae.delete_flag = '0'
AND ae.class_enum = #{classEnum}
AND ae.status_enum != #{toBeRegistered}
AND ae.status_enum != #{alreadySettled}
AND ae.status_enum != #{registered}
AND EXISTS(
SELECT 1
FROM adm_practitioner_role
WHERE delete_flag = '0'
AND practitioner_id = #{practitionerId}
AND org_id = ae.organization_id
)) AS rpmi
<if test="ew != null and ew.sqlSegment != null and ew.sqlSegment != ''">
WHERE ${ew.sqlSegment}
</if>
ORDER BY rpmi.patient_id, rpmi.encounter_id DESC
</select>
<!-- 用于分页的COUNT查询与主查询保持一致的去重逻辑 -->
<select id="getRegPatientMainInfoCount" resultType="java.lang.Long">
SELECT COUNT(*) FROM (
SELECT DISTINCT ON (rpmi.patient_id)
rpmi.patient_id
FROM (SELECT ae.tenant_id,
ae.ID AS encounter_id,
ae.status_enum AS status_enum,
ae.bus_no AS bus_no,
ae.start_time AS in_hospital_time,
(EXTRACT(DAY FROM (CURRENT_DATE - ae.start_time)) :: INTEGER + 1) AS in_hospital_days,
ae.end_time AS out_hospital_time,
ap.ID AS patient_id,
ap.NAME AS patient_name,
ap.gender_enum AS gender_enum,
ap.birth_date AS birth_date,
alw.NAME AS ward_name,
alh.NAME AS house_name,
alb.NAME AS bed_name,
aelb.start_time AS in_org_time,
ao.id AS in_hospital_org_id,
ao.NAME AS in_hospital_org_name,
aa.id AS account_id,
aa.contract_no AS contract_no,
fc.contract_name AS contract_name,
ccd.NAME AS reg_diagnosis_name
FROM adm_encounter AS ae
LEFT JOIN adm_patient AS ap ON ap.ID = ae.patient_id
AND ap.delete_flag = '0'
LEFT JOIN adm_organization AS ao ON ao.ID = ae.organization_id
AND ao.delete_flag = '0'
LEFT JOIN adm_encounter_location AS aelw ON aelw.encounter_id = ae.ID
AND aelw.delete_flag = '0'
AND aelw.form_enum = #{wardEnum}
AND aelw.status_enum = #{encounterActivityStatus}
LEFT JOIN adm_location AS alw ON alw.ID = aelw.location_id
AND alw.delete_flag = '0'
LEFT JOIN adm_encounter_location AS aelh ON aelh.encounter_id = ae.ID
AND aelh.delete_flag = '0'
AND aelh.form_enum = #{houseEnum}
AND aelh.status_enum = #{encounterActivityStatus}
LEFT JOIN adm_location AS alh ON alh.ID = aelh.location_id
AND alh.delete_flag = '0'
LEFT JOIN adm_encounter_location AS aelb ON aelb.encounter_id = ae.ID
AND aelb.delete_flag = '0'
AND aelb.form_enum = #{bedEnum}
AND aelb.status_enum = #{encounterActivityStatus}
LEFT JOIN adm_location AS alb ON alb.ID = aelb.location_id
AND alb.delete_flag = '0'
INNER JOIN adm_account AS aa ON aa.encounter_id = ae.ID
AND aa.delete_flag = '0'
AND aa.encounter_flag = 1
LEFT JOIN fin_contract AS fc ON fc.bus_no = aa.contract_no
AND fc.delete_flag = '0'
LEFT JOIN adm_encounter_diagnosis AS aed ON aed.encounter_id = ae.ID
AND aed.delete_flag = '0'
AND aed.maindise_flag = #{maindiseFlag}
LEFT JOIN cli_condition AS cc ON cc.ID = aed.condition_id
AND cc.delete_flag = '0'
LEFT JOIN cli_condition_definition AS ccd ON ccd.ID = cc.definition_id
AND ccd.delete_flag = '0'
WHERE ae.delete_flag = '0'
AND ae.class_enum = #{classEnum}
AND ae.status_enum != #{toBeRegistered}
AND ae.status_enum != #{alreadySettled}
AND ae.status_enum != #{registered}
AND EXISTS(
SELECT 1
FROM adm_practitioner_role
WHERE delete_flag = '0'
AND practitioner_id = #{practitionerId}
AND org_id = ae.organization_id
)) AS rpmi
<if test="ew != null and ew.sqlSegment != null and ew.sqlSegment != ''">
WHERE ${ew.sqlSegment}
</if>
ORDER BY rpmi.patient_id, rpmi.encounter_id DESC
) AS distinct_patients
</select>
<select id="getRegRequestBaseInfo" resultType="com.openhis.web.regdoctorstation.dto.RegRequestBaseDto">
(SELECT 1 AS advice_type,
T1.id AS request_id,
T1.id || '-1' AS unique_key,
T1.practitioner_id AS requester_id,
T1.create_time AS request_time,
CASE WHEN T1.practitioner_id = #{practitionerId} THEN '1' ELSE '0' END AS biz_request_flag,
T1.content_json AS content_json,
T1.skin_test_flag AS skin_test_flag,
T1.infusion_flag AS inject_flag,
T1.group_id AS group_id,
T2.NAME AS advice_name,
T3.total_volume AS volume,
T1.lot_number AS lot_number,
T1.quantity AS quantity,
T1.unit_code AS unit_code,
T1.status_enum AS status_enum,
T1.method_code AS method_code,
T1.rate_code AS rate_code,
T1.dose AS dose,
T1.dose_unit_code AS dose_unit_code,
T4.id AS charge_item_id,
T4.total_price AS total_price,
T4.status_enum AS charge_status,
al.id AS position_id,
al.name AS position_name,
T1.dispense_per_duration AS dispense_per_duration,
T2.part_percent AS part_percent,
ccd.name AS condition_definition_name,
T1.therapy_enum AS therapyEnum,
T1.sort_number AS sort_number,
T1.based_on_id AS based_on_id
FROM med_medication_request AS T1
LEFT JOIN med_medication_definition AS T2 ON T2.ID = T1.medication_id
AND T2.delete_flag = '0'
LEFT JOIN med_medication AS T3 ON T3.medication_def_id = T2.ID
AND T3.delete_flag = '0'
LEFT JOIN adm_charge_item AS T4 ON T4.service_id = T1.ID AND T4.delete_flag = '0' AND
T4.service_table = #{MED_MEDICATION_REQUEST}
LEFT JOIN adm_location AS al ON al.ID = T1.perform_location AND al.delete_flag = '0'
LEFT JOIN cli_condition AS cc ON cc.id = T1.condition_id AND cc.delete_flag = '0'
LEFT JOIN cli_condition_definition AS ccd ON ccd.id = cc.definition_id
WHERE T1.delete_flag = '0' AND T1.tcm_flag = 0 AND T1.generate_source_enum = #{generateSourceEnum}
<if test="historyFlag == '0'.toString()">
AND T1.encounter_id = #{encounterId}
</if>
<if test="historyFlag == '1'.toString()">
AND T1.patient_id = #{patientId} AND T1.encounter_id != #{encounterId}
</if>
AND T1.refund_medicine_id IS NULL
ORDER BY T1.status_enum,T1.sort_number,T1.group_id)
UNION ALL
(SELECT 2 AS advice_type,
T1.id AS request_id,
T1.id || '-2' AS unique_key,
T1.requester_id AS requester_id,
T1.create_time AS request_time,
CASE WHEN T1.requester_id = #{practitionerId} THEN '1' ELSE '0' END AS biz_request_flag,
T1.content_json AS content_json,
null AS skin_test_flag,
null AS inject_flag,
null AS group_id,
T2.NAME AS advice_name,
T2.SIZE AS volume,
T1.lot_number AS lot_number,
T1.quantity AS quantity,
T1.unit_code AS unit_code,
T1.status_enum AS status_enum,
'' AS method_code,
T1.rate_code AS rate_code,
NULL AS dose,
'' AS dose_unit_code,
T3.id AS charge_item_id,
T3.total_price AS total_price,
T3.status_enum AS charge_status,
al.id AS position_id,
al.name AS position_name,
null AS dispense_per_duration,
T2.part_percent AS part_percent,
'' AS condition_definition_name,
2 AS therapyEnum,
99 AS sort_number,
T1.based_on_id AS based_on_id
FROM wor_device_request AS T1
LEFT JOIN adm_device_definition AS T2 ON T2.ID = T1.device_def_id
AND T2.delete_flag = '0'
LEFT JOIN adm_charge_item AS T3
ON T3.service_id = T1.ID AND T3.delete_flag = '0' AND
T3.service_table = #{WOR_DEVICE_REQUEST}
LEFT JOIN adm_location AS al ON al.ID = T1.perform_location AND al.delete_flag = '0'
WHERE T1.delete_flag = '0' AND T1.generate_source_enum = #{generateSourceEnum}
<if test="historyFlag == '0'.toString()">
AND T1.encounter_id = #{encounterId}
</if>
<if test="historyFlag == '1'.toString()">
AND T1.patient_id = #{patientId} AND T1.encounter_id != #{encounterId}
</if>
AND T1.refund_device_id IS NULL
ORDER BY T1.status_enum)
UNION ALL
(SELECT 3 AS advice_type,
T1.id AS request_id,
T1.id || '-3' AS unique_key,
T1.requester_id AS requester_id,
T1.create_time AS request_time,
CASE WHEN T1.requester_id = #{practitionerId} THEN '1' ELSE '0' END AS biz_request_flag,
T1.content_json AS content_json,
null AS skin_test_flag,
null AS inject_flag,
null AS group_id,
T2.NAME AS advice_name,
'' AS volume,
'' AS lot_number,
T1.quantity AS quantity,
T1.unit_code AS unit_code,
T1.status_enum AS status_enum,
'' AS method_code,
'' AS rate_code,
NULL AS dose,
'' AS dose_unit_code,
T3.id AS charge_item_id,
T3.total_price AS total_price,
T3.status_enum AS charge_status,
ao.id AS position_id,
ao.name AS position_name,
null AS dispense_per_duration,
1 AS part_percent,
'' AS condition_definition_name,
T1.therapy_enum AS therapyEnum,
99 AS sort_number,
T1.based_on_id AS based_on_id
FROM wor_service_request AS T1
LEFT JOIN wor_activity_definition AS T2
ON T2.ID = T1.activity_id
AND T2.delete_flag = '0'
LEFT JOIN adm_charge_item AS T3 ON T3.service_id = T1.ID AND T3.delete_flag = '0' AND
T3.service_table = #{WOR_SERVICE_REQUEST}
LEFT JOIN adm_organization AS ao ON ao.ID = T1.org_id AND ao.delete_flag = '0'
WHERE T1.delete_flag = '0' AND T1.generate_source_enum = #{generateSourceEnum}
AND T1.parent_id IS NULL
<if test="historyFlag == '0'.toString()">
AND T1.encounter_id = #{encounterId}
</if>
<if test="historyFlag == '1'.toString()">
AND T1.patient_id = #{patientId} AND T1.encounter_id != #{encounterId}
</if>
ORDER BY T1.status_enum)
</select>
<select id="getAmount" resultType="com.openhis.web.inhospitalnursestation.dto.EncounterAccountDto">
SELECT final_res.id,
final_res.insutype,
final_res.encounter_id,
final_res.advance_amount,
final_res.total_amount,
final_res.balance_amount
FROM (SELECT aa.tenant_id,
aa.id,
aa.insutype,
aa.encounter_id,
aa.balance_amount AS advance_amount,
COALESCE(
SUM(CASE WHEN aci.status_enum IN (#{billed}, #{billable}) THEN aci.total_price ELSE 0 END),
0) AS total_amount,
(
aa.balance_amount
- COALESCE(SUM(CASE
WHEN aci.status_enum IN (#{billed}, #{billable}) THEN aci.total_price
ELSE 0 END), 0)
+ COALESCE(SUM(CASE WHEN aci.status_enum = #{refunded} THEN aci.total_price ELSE 0 END), 0)
) AS balance_amount
FROM adm_account aa
LEFT JOIN adm_charge_item aci
ON aa.encounter_id = aci.encounter_id
AND aci.delete_flag = '0'
WHERE aa.type_code = #{personalCashAccount}
AND aa.delete_flag = '0'
GROUP BY aa.tenant_id, aa.id, aa.insutype, aa.encounter_id, aa.balance_amount) AS final_res
<if test="ew != null and ew.sqlSegment != null and ew.sqlSegment != ''">
WHERE ${ew.sqlSegment}
</if>
</select>
</mapper>