143 lines
4.1 KiB
SQL
143 lines
4.1 KiB
SQL
-- ============================================
|
||
-- 检查 wor_activity_definition 表中 pricing_flag = 0 的数据
|
||
-- 用途:分析哪些项目被标记为"不允许划价",是否符合业务预期
|
||
-- ============================================
|
||
|
||
-- 1. 查看所有 pricing_flag = 0 的项目详情
|
||
SELECT
|
||
id,
|
||
bus_no,
|
||
name AS activity_name,
|
||
category_code,
|
||
type_enum,
|
||
pricing_flag,
|
||
status_enum,
|
||
org_id,
|
||
location_id,
|
||
description_text,
|
||
create_time,
|
||
update_time
|
||
FROM wor_activity_definition
|
||
WHERE delete_flag = '0'
|
||
AND pricing_flag = '0' -- 注意:字段类型是 char(1),所以是字符串 '0'
|
||
ORDER BY id;
|
||
|
||
-- 2. 统计 pricing_flag = 0 的项目数量(按状态)
|
||
SELECT
|
||
status_enum,
|
||
COUNT(*) AS count,
|
||
CASE
|
||
WHEN status_enum = 1 THEN '激活'
|
||
WHEN status_enum = 2 THEN '停用'
|
||
ELSE '其他'
|
||
END AS status_desc
|
||
FROM wor_activity_definition
|
||
WHERE delete_flag = '0'
|
||
AND pricing_flag = '0'
|
||
GROUP BY status_enum
|
||
ORDER BY status_enum;
|
||
|
||
-- 3. 检查 pricing_flag = 0 的项目是否有关联的费用定价
|
||
SELECT
|
||
T1.id,
|
||
T1.bus_no,
|
||
T1.name AS activity_name,
|
||
T1.pricing_flag,
|
||
T1.status_enum,
|
||
T2.id AS charge_item_definition_id,
|
||
T2.charge_name,
|
||
T2.price,
|
||
T2.status_enum AS charge_status,
|
||
CASE
|
||
WHEN T2.id IS NOT NULL THEN '有费用定价但不允许划价(可能异常)'
|
||
ELSE '无费用定价,不允许划价(正常)'
|
||
END AS analysis
|
||
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.pricing_flag = '0'
|
||
ORDER BY T1.id;
|
||
|
||
-- 4. 检查 pricing_flag = 0 的项目是否在收费项目表中被使用
|
||
SELECT
|
||
T1.id AS activity_id,
|
||
T1.bus_no,
|
||
T1.name AS activity_name,
|
||
T1.pricing_flag,
|
||
COUNT(T3.id) AS charge_item_count,
|
||
CASE
|
||
WHEN COUNT(T3.id) > 0 THEN '已被使用(可能异常:不允许划价但已有收费记录)'
|
||
ELSE '未被使用(正常)'
|
||
END AS analysis
|
||
FROM wor_activity_definition AS T1
|
||
LEFT JOIN adm_charge_item AS T3
|
||
ON T3.product_id = T1.id
|
||
AND T3.context_enum = 3 -- ACTIVITY
|
||
AND T3.delete_flag = '0'
|
||
WHERE T1.delete_flag = '0'
|
||
AND T1.pricing_flag = '0'
|
||
GROUP BY T1.id, T1.bus_no, T1.name, T1.pricing_flag
|
||
HAVING COUNT(T3.id) > 0 -- 只显示已被使用的
|
||
ORDER BY charge_item_count DESC;
|
||
|
||
-- 5. 按类别统计 pricing_flag = 0 的项目
|
||
SELECT
|
||
category_code,
|
||
COUNT(*) AS count,
|
||
STRING_AGG(name, ', ') AS activity_names -- 列出项目名称
|
||
FROM wor_activity_definition
|
||
WHERE delete_flag = '0'
|
||
AND pricing_flag = '0'
|
||
AND status_enum = 1 -- 只统计激活的
|
||
GROUP BY category_code
|
||
ORDER BY category_code;
|
||
|
||
-- 6. 对比:pricing_flag = 0 和 pricing_flag = 1 的项目特征
|
||
SELECT
|
||
pricing_flag,
|
||
COUNT(*) AS count,
|
||
COUNT(DISTINCT category_code) AS category_count,
|
||
COUNT(DISTINCT org_id) AS org_count,
|
||
STRING_AGG(DISTINCT category_code::text, ', ') AS categories
|
||
FROM wor_activity_definition
|
||
WHERE delete_flag = '0'
|
||
AND status_enum = 1
|
||
AND pricing_flag IN ('0', '1')
|
||
GROUP BY pricing_flag
|
||
ORDER BY pricing_flag;
|
||
|
||
-- 7. 检查是否有子项的项目(childrenJson 不为空)被标记为 pricing_flag = 0
|
||
SELECT
|
||
id,
|
||
bus_no,
|
||
name AS activity_name,
|
||
pricing_flag,
|
||
children_json,
|
||
CASE
|
||
WHEN children_json IS NOT NULL AND children_json != '' THEN '有子项但不允许划价(可能是套餐子项)'
|
||
ELSE '无子项'
|
||
END AS analysis
|
||
FROM wor_activity_definition
|
||
WHERE delete_flag = '0'
|
||
AND pricing_flag = '0'
|
||
AND children_json IS NOT NULL
|
||
AND children_json != ''
|
||
ORDER BY id;
|
||
|
||
-- 8. 查看 pricing_flag 字段的所有可能值(包括 NULL)
|
||
SELECT
|
||
COALESCE(pricing_flag::text, 'NULL') AS pricing_flag_value,
|
||
COUNT(*) AS count,
|
||
ROUND(COUNT(*) * 100.0 / SUM(COUNT(*)) OVER (), 2) AS percentage
|
||
FROM wor_activity_definition
|
||
WHERE delete_flag = '0'
|
||
AND status_enum = 1
|
||
GROUP BY pricing_flag
|
||
ORDER BY pricing_flag NULLS LAST;
|
||
|
||
|