挂号补单功能的完善

This commit is contained in:
2026-01-14 10:12:25 +08:00
parent 8e61490005
commit d8c4348341
8 changed files with 423 additions and 32 deletions

View File

@@ -0,0 +1,212 @@
-- 根据流水号查询病人信息
--
-- 流水号格式YYYYMMDD-XXX例如20260109-001
-- - 前面8位是日期YYYYMMDD
-- - 后面3位是序号XXX对应数据库的 display_order
--
-- 说明:
-- display_order 是按"科室+医生+当天"自增的,所以同一天不同科室/不同医生可能有相同的序号
-- 如果只知道序号(如 001建议配合科室、医生、日期范围一起查询
-- ========================================
-- 方案1知道完整流水号20260109-001
-- ========================================
-- 参数说明:
-- :serial_no = '20260109-001' -- 完整流水号
--
-- 解析逻辑:
-- 日期20260109 -> 2026-01-09
-- 序号001 -> 1
WITH parsed AS (
SELECT
-- 提取日期部分前8位并转换为日期格式
TO_DATE(SUBSTRING(:serial_no FROM 1 FOR 8), 'YYYYMMDD') AS target_date,
-- 提取序号部分最后3位并转换为整数
CAST(SUBSTRING(:serial_no FROM 10) AS INTEGER) AS target_order
)
SELECT
e.id AS ID,
e.bus_no AS ,
DATE(e.start_time) AS ,
e.start_time AS ,
e.organization_id AS ID,
e.registrar_id AS ID,
e.display_order AS ,
-- 计算完整流水号(用于验证)
TO_CHAR(e.start_time, 'YYYYMMDD') || '-' || LPAD(e.display_order::text, 3, '0') AS ,
p.id AS ID,
p.name AS ,
p.bus_no AS ,
p.gender AS ,
p.birth_date AS ,
p.phone AS ,
e.status_enum AS
FROM adm_encounter e
INNER JOIN adm_patient p ON e.patient_id = p.id AND p.delete_flag = '0'
CROSS JOIN parsed
WHERE e.delete_flag = '0'
AND DATE(e.start_time) = parsed.target_date
AND e.display_order = parsed.target_order
ORDER BY e.start_time DESC
LIMIT 10;
-- ========================================
-- 方案2只知道序号001配合其他条件查询
-- ========================================
-- 参数说明:
-- :order_no = '001' -- 序号(不带日期)
-- :start_date = '2026-01-01' -- 开始日期(可选,缩小范围)
-- :end_date = '2026-01-31' -- 结束日期(可选,缩小范围)
-- :organization_id = 123 -- 科室ID可选精确匹配
-- :registrar_id = 456 -- 医生ID可选精确匹配
-- :patient_name = '张三' -- 患者姓名(可选,模糊匹配)
SELECT
e.id AS ID,
e.bus_no AS ,
DATE(e.start_time) AS ,
e.start_time AS ,
TO_CHAR(e.start_time, 'YYYYMMDD') || '-' || LPAD(e.display_order::text, 3, '0') AS ,
e.organization_id AS ID,
e.registrar_id AS ID,
e.display_order AS ,
p.id AS ID,
p.name AS ,
p.bus_no AS ,
p.phone AS ,
e.status_enum AS
FROM adm_encounter e
INNER JOIN adm_patient p ON e.patient_id = p.id AND p.delete_flag = '0'
WHERE e.delete_flag = '0'
AND e.display_order = CAST(:order_no AS INTEGER) -- 序号匹配
-- 以下条件可选,去掉注释并根据需要填入值
-- AND DATE(e.start_time) >= CAST(:start_date AS DATE) -- 日期范围:开始
-- AND DATE(e.start_time) <= CAST(:end_date AS DATE) -- 日期范围:结束
-- AND e.organization_id = CAST(:organization_id AS BIGINT) -- 科室匹配
-- AND e.registrar_id = CAST(:registrar_id AS BIGINT) -- 医生匹配
-- AND p.name LIKE '%' || :patient_name || '%' -- 患者姓名模糊匹配
ORDER BY e.start_time DESC
LIMIT 50;
-- ========================================
-- 方案3按患者姓名 + 大概日期范围查询(最常用)
-- ========================================
-- 参数说明:
-- :patient_name = '张三' -- 患者姓名(模糊匹配)
-- :start_date = '2026-01-01' -- 开始日期
-- :end_date = '2026-01-31' -- 结束日期
SELECT
e.id AS ID,
e.bus_no AS ,
DATE(e.start_time) AS ,
e.start_time AS ,
TO_CHAR(e.start_time, 'YYYYMMDD') || '-' || LPAD(e.display_order::text, 3, '0') AS ,
e.organization_id AS ID,
e.registrar_id AS ID,
e.display_order AS ,
p.id AS ID,
p.name AS ,
p.bus_no AS ,
p.phone AS ,
e.status_enum AS
FROM adm_encounter e
INNER JOIN adm_patient p ON e.patient_id = p.id AND p.delete_flag = '0'
WHERE e.delete_flag = '0'
AND p.name LIKE '%' || :patient_name || '%'
AND DATE(e.start_time) >= CAST(:start_date AS DATE)
AND DATE(e.start_time) <= CAST(:end_date AS DATE)
ORDER BY e.start_time DESC;
-- ========================================
-- 方案4按就诊卡号查询最准确
-- ========================================
-- 参数说明:
-- :card_no = '12345678' -- 就诊卡号
SELECT
e.id AS ID,
e.bus_no AS ,
DATE(e.start_time) AS ,
e.start_time AS ,
TO_CHAR(e.start_time, 'YYYYMMDD') || '-' || LPAD(e.display_order::text, 3, '0') AS ,
e.organization_id AS ID,
e.registrar_id AS ID,
e.display_order AS ,
p.id AS ID,
p.name AS ,
p.bus_no AS ,
COALESCE(
(SELECT identifier_no
FROM adm_patient_identifier
WHERE patient_id = p.id
AND delete_flag = '0'
AND identifier_no IS NOT NULL
AND identifier_no != ''
ORDER BY create_time ASC
LIMIT 1),
p.bus_no,
''
) AS ,
p.phone AS ,
e.status_enum AS
FROM adm_encounter e
INNER JOIN adm_patient p ON e.patient_id = p.id AND p.delete_flag = '0'
WHERE e.delete_flag = '0'
AND (
-- 优先匹配 identifier_no
EXISTS (
SELECT 1
FROM adm_patient_identifier api
WHERE api.patient_id = p.id
AND api.delete_flag = '0'
AND api.identifier_no = :card_no
)
OR
-- 备用:匹配 patient.bus_no
p.bus_no = :card_no
)
ORDER BY e.start_time DESC
LIMIT 20;
-- ========================================
-- 方案5模糊查询流水号部分匹配
-- ========================================
-- 参数说明:
-- :serial_part = '20260109' -- 只输入日期部分
-- 或
-- :serial_part = '001' -- 只输入序号部分
-- 或
-- :serial_part = '20260109-00' -- 输入部分(前缀匹配)
SELECT
e.id AS ID,
e.bus_no AS ,
DATE(e.start_time) AS ,
e.start_time AS ,
TO_CHAR(e.start_time, 'YYYYMMDD') || '-' || LPAD(e.display_order::text, 3, '0') AS ,
e.organization_id AS ID,
e.registrar_id AS ID,
e.display_order AS ,
p.id AS ID,
p.name AS ,
p.bus_no AS ,
p.phone AS ,
e.status_enum AS
FROM adm_encounter e
INNER JOIN adm_patient p ON e.patient_id = p.id AND p.delete_flag = '0'
WHERE e.delete_flag = '0'
AND (
-- 匹配日期部分如输入20260109
TO_CHAR(e.start_time, 'YYYYMMDD') LIKE :serial_part || '%'
OR
-- 匹配序号部分如输入001
LPAD(e.display_order::text, 3, '0') LIKE '%' || :serial_part || '%'
OR
-- 匹配完整流水号前缀如输入20260109-00
(TO_CHAR(e.start_time, 'YYYYMMDD') || '-' || LPAD(e.display_order::text, 3, '0')) LIKE :serial_part || '%'
)
ORDER BY e.start_time DESC
LIMIT 50;