105 lines
3.7 KiB
SQL
105 lines
3.7 KiB
SQL
-- 检查流水号(display_order)是否按“科室+医生+当天”正确递增
|
||
--
|
||
-- 说明:
|
||
-- 1. display_order 存的是纯数字(1, 2, 3...),不带时间戳前缀
|
||
-- 2. 时间戳前缀(如 20260109)是在前端显示时加上的
|
||
-- 3. 后端用 Redis key "ORG-{科室ID}-DOC-{医生ID}" 按天自增
|
||
--
|
||
-- 如何判断逻辑是否正确:
|
||
-- 同一科室、同一医生、同一天的记录,display_order 应该递增(1, 2, 3...)
|
||
-- 不同科室、不同医生、不同天的记录,可能都是 1(这是正常的)
|
||
|
||
-- ========================================
|
||
-- 查询1:按“科室+医生+日期”分组,看每组内的 display_order 是否递增
|
||
-- ========================================
|
||
SELECT
|
||
DATE(start_time) AS 日期,
|
||
organization_id AS 科室ID,
|
||
registrar_id AS 医生ID,
|
||
COUNT(*) AS 该组记录数,
|
||
MIN(display_order) AS 最小序号,
|
||
MAX(display_order) AS 最大序号,
|
||
STRING_AGG(display_order::text, ', ' ORDER BY start_time) AS 序号列表,
|
||
STRING_AGG(id::text, ', ' ORDER BY start_time) AS 记录ID列表
|
||
FROM adm_encounter
|
||
WHERE delete_flag = '0'
|
||
AND start_time >= CURRENT_DATE - INTERVAL '7 days' -- 只看最近7天
|
||
AND display_order IS NOT NULL
|
||
GROUP BY DATE(start_time), organization_id, registrar_id
|
||
ORDER BY 日期 DESC, 科室ID, 医生ID;
|
||
|
||
-- ========================================
|
||
-- 查询2:详细查看每条记录,看同组内的序号是否连续
|
||
-- ========================================
|
||
SELECT
|
||
id AS 记录ID,
|
||
DATE(start_time) AS 日期,
|
||
organization_id AS 科室ID,
|
||
registrar_id AS 医生ID,
|
||
start_time AS 挂号时间,
|
||
display_order AS 流水号,
|
||
-- 计算:同组内的序号应该是 1, 2, 3...,看是否有重复或跳号
|
||
ROW_NUMBER() OVER (
|
||
PARTITION BY DATE(start_time), organization_id, registrar_id
|
||
ORDER BY start_time
|
||
) AS 应该是第几个,
|
||
CASE
|
||
WHEN display_order = ROW_NUMBER() OVER (
|
||
PARTITION BY DATE(start_time), organization_id, registrar_id
|
||
ORDER BY start_time
|
||
) THEN '✓ 正常'
|
||
ELSE '✗ 异常'
|
||
END AS 是否正常
|
||
FROM adm_encounter
|
||
WHERE delete_flag = '0'
|
||
AND start_time >= CURRENT_DATE - INTERVAL '7 days'
|
||
AND display_order IS NOT NULL
|
||
ORDER BY DATE(start_time) DESC, organization_id, registrar_id, start_time;
|
||
|
||
-- ========================================
|
||
-- 查询3:只看今天的数据(最直观)
|
||
-- ========================================
|
||
SELECT
|
||
id AS 记录ID,
|
||
organization_id AS 科室ID,
|
||
registrar_id AS 医生ID,
|
||
start_time AS 挂号时间,
|
||
display_order AS 流水号
|
||
FROM adm_encounter
|
||
WHERE delete_flag = '0'
|
||
AND DATE(start_time) = CURRENT_DATE
|
||
AND display_order IS NOT NULL
|
||
ORDER BY organization_id, registrar_id, start_time;
|
||
|
||
-- ========================================
|
||
-- 查询4:发现问题 - 找出同组内 display_order 重复的记录
|
||
-- ========================================
|
||
WITH ranked AS (
|
||
SELECT
|
||
id,
|
||
DATE(start_time) AS reg_date,
|
||
organization_id,
|
||
registrar_id,
|
||
start_time,
|
||
display_order,
|
||
ROW_NUMBER() OVER (
|
||
PARTITION BY DATE(start_time), organization_id, registrar_id
|
||
ORDER BY start_time
|
||
) AS should_be_order
|
||
FROM adm_encounter
|
||
WHERE delete_flag = '0'
|
||
AND start_time >= CURRENT_DATE - INTERVAL '7 days'
|
||
AND display_order IS NOT NULL
|
||
)
|
||
SELECT
|
||
reg_date AS 日期,
|
||
organization_id AS 科室ID,
|
||
registrar_id AS 医生ID,
|
||
COUNT(*) AS 重复数量,
|
||
STRING_AGG(id::text || '->' || display_order::text, ', ') AS 问题记录
|
||
FROM ranked
|
||
WHERE display_order != should_be_order
|
||
GROUP BY reg_date, organization_id, registrar_id
|
||
ORDER BY reg_date DESC;
|
||
|