Files
his/openhis-server-new/sql/query_pricing_flag_distribution.sql

145 lines
4.4 KiB
SQL
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.

-- ============================================
-- 查询诊疗项目 pricing_flag 字段分布情况
-- 用途:了解哪些项目允许划价,哪些不允许
-- ============================================
-- 1. 统计 pricing_flag 字段的分布情况
SELECT
COUNT(*) AS total_count,
COUNT(CASE WHEN pricing_flag = 1 THEN 1 END) AS pricing_flag_1_count, -- 允许划价
COUNT(CASE WHEN pricing_flag = 0 THEN 1 END) AS pricing_flag_0_count, -- 不允许划价
COUNT(CASE WHEN pricing_flag IS NULL THEN 1 END) AS pricing_flag_null_count, -- 未设置
ROUND(COUNT(CASE WHEN pricing_flag = 1 THEN 1 END) * 100.0 / COUNT(*), 2) AS flag_1_percent,
ROUND(COUNT(CASE WHEN pricing_flag = 0 THEN 1 END) * 100.0 / COUNT(*), 2) AS flag_0_percent,
ROUND(COUNT(CASE WHEN pricing_flag IS NULL THEN 1 END) * 100.0 / COUNT(*), 2) AS flag_null_percent
FROM wor_activity_definition
WHERE delete_flag = '0'
AND status_enum = 1; -- 只统计激活状态的项目
-- 2. 查看所有允许划价的项目pricing_flag = 1 或 NULL
SELECT
id,
bus_no,
name AS activity_name,
pricing_flag,
status_enum,
org_id,
category_code,
type_enum,
CASE
WHEN pricing_flag = 1 THEN '允许划价'
WHEN pricing_flag = 0 THEN '不允许划价'
WHEN pricing_flag IS NULL THEN '未设置(默认允许)'
ELSE '未知'
END AS pricing_flag_desc
FROM wor_activity_definition
WHERE delete_flag = '0'
AND status_enum = 1
AND (pricing_flag = 1 OR pricing_flag IS NULL) -- 之前过滤条件
ORDER BY id;
-- 3. 查看不允许划价的项目pricing_flag = 0
SELECT
id,
bus_no,
name AS activity_name,
pricing_flag,
status_enum,
org_id,
category_code,
type_enum,
description_text,
'不允许划价' AS pricing_flag_desc
FROM wor_activity_definition
WHERE delete_flag = '0'
AND status_enum = 1
AND pricing_flag = 0 -- 这些项目之前不会显示
ORDER BY id;
-- 4. 查看未设置 pricing_flag 的项目NULL
SELECT
id,
bus_no,
name AS activity_name,
pricing_flag,
status_enum,
org_id,
category_code,
type_enum,
'未设置(默认允许)' AS pricing_flag_desc
FROM wor_activity_definition
WHERE delete_flag = '0'
AND status_enum = 1
AND pricing_flag IS NULL
ORDER BY id;
-- 5. 按科室统计 pricing_flag 分布
SELECT
org_id,
COUNT(*) AS total_count,
COUNT(CASE WHEN pricing_flag = 1 THEN 1 END) AS flag_1_count,
COUNT(CASE WHEN pricing_flag = 0 THEN 1 END) AS flag_0_count,
COUNT(CASE WHEN pricing_flag IS NULL THEN 1 END) AS flag_null_count
FROM wor_activity_definition
WHERE delete_flag = '0'
AND status_enum = 1
GROUP BY org_id
ORDER BY org_id;
-- 6. 按类别统计 pricing_flag 分布
SELECT
category_code,
COUNT(*) AS total_count,
COUNT(CASE WHEN pricing_flag = 1 THEN 1 END) AS flag_1_count,
COUNT(CASE WHEN pricing_flag = 0 THEN 1 END) AS flag_0_count,
COUNT(CASE WHEN pricing_flag IS NULL THEN 1 END) AS flag_null_count
FROM wor_activity_definition
WHERE delete_flag = '0'
AND status_enum = 1
GROUP BY category_code
ORDER BY category_code;
-- 7. 检查是否有费用定价关联的项目,但 pricing_flag = 0
SELECT
T1.id,
T1.bus_no,
T1.name AS activity_name,
T1.pricing_flag,
T2.id AS charge_item_definition_id,
T2.charge_name,
T2.price,
'有费用定价但不允许划价' AS issue_desc
FROM wor_activity_definition AS T1
LEFT JOIN adm_charge_item_definition AS T2
ON T2.instance_id = T1.id
AND T2.delete_flag = '0'
AND T2.status_enum = 1
AND T2.instance_table = 'wor_activity_definition'
WHERE T1.delete_flag = '0'
AND T1.status_enum = 1
AND T1.pricing_flag = 0
AND T2.id IS NOT NULL -- 有关联的费用定价
ORDER BY T1.id;
-- 8. 检查没有费用定价关联的项目,但 pricing_flag = 1
SELECT
T1.id,
T1.bus_no,
T1.name AS activity_name,
T1.pricing_flag,
T2.id AS charge_item_definition_id,
'允许划价但没有费用定价' AS issue_desc
FROM wor_activity_definition AS T1
LEFT JOIN adm_charge_item_definition AS T2
ON T2.instance_id = T1.id
AND T2.delete_flag = '0'
AND T2.status_enum = 1
AND T2.instance_table = 'wor_activity_definition'
WHERE T1.delete_flag = '0'
AND T1.status_enum = 1
AND (T1.pricing_flag = 1 OR T1.pricing_flag IS NULL)
AND T2.id IS NULL -- 没有关联的费用定价
ORDER BY T1.id;