挂号补单功能的完善
This commit is contained in:
212
query_patient_by_serial_no.sql
Normal file
212
query_patient_by_serial_no.sql
Normal 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;
|
||||
|
||||
Reference in New Issue
Block a user