DROP TABLE ods_history_metric_save; CREATE TABLE ods_history_metric_save( dt VARCHAR(50) COMMENT '时间' ,extract_time VARCHAR(50) COMMENT '抽数时间' ,metric_name VARCHAR(50) COMMENT '指标名称' ,metric_value VARCHAR(50) COMMENT '指标值' )COMMENT = '关键指标历史数据保留'; SELECT * FROM ods_history_metric_save; /* 总裁驾驶舱、财务看板PC端和移动端: 1、今日收费:最新拉取数据=上次拉取数据时、08:00之前数据大于50w时;推送角色 2、今日收费:最新拉取数据为空; 3、当期欠费金额:当日数据>昨日数据时; 4、往期欠费金额:当日数据>昨日数据时; 5、当期收缴率:当日数据<昨日数据时; 6、往期收缴率:当日数据<昨日数据时; 7、月度累计收费:当日数据<昨日数据时; 8、年度累计收费:当日数据<昨日数据时; */ -- 当期欠费金额 -- 往期欠费金额 -- 当期收缴率 -- 往期收缴率 WITH base_metric AS( select sum((ifnull(pr_paid_cu_amt,0) + ifnull(cu_paid_cu_amt,0) - ifnull(pr_offset_cu_amt,0) - ifnull(cu_offset_cu_amt,0))) / sum((ifnull(cu_receivable_amt,0) + ifnull(pr_exempt_cu_amt,0) + ifnull(cu_exempt_cu_amt,0))) cu_collection_rate -- 当期收缴率 ,sum((- ifnull(cu_paid_pr_amt,0) - ifnull(cu_offset_pr_amt,0))) / sum((ifnull(pr_total_receivable_amt,0) + ifnull(pr_total_received_amt,0) + ifnull(cu_early_exempt_pr_amt,0) + ifnull(cu_exempt_pr_amt,0))) pr_collection_rate -- 往期收缴率 ,sum((ifnull(pr_total_receivable_amt,0) + ifnull(pr_total_received_amt,0) + ifnull(cu_early_exempt_pr_amt,0) + ifnull(cu_exempt_pr_amt,0))-(- ifnull(cu_paid_pr_amt,0) - ifnull(cu_offset_pr_amt,0)))/10000 pr_owed_amt -- 往期欠费金额 ,sum((ifnull(cu_receivable_amt,0) + ifnull(pr_exempt_cu_amt,0) + ifnull(cu_exempt_cu_amt,0))-(ifnull(pr_paid_cu_amt,0) + ifnull(cu_paid_cu_amt,0) - ifnull(pr_offset_cu_amt,0) - ifnull(cu_offset_cu_amt,0)))/10000 cu_owed_amt -- 当期欠费金额 ,0 AS thisy_paid_amt -- 年度累计收费 ,0 AS thism_paid_amt -- 月度累计收费 from dwd_finance_fees_serial_d where ParentCostCode = '0001' and organ_name not in ('东湖商管','领悦总部','演示机构') and commid not in(select comm_id from ods_remove_comm) and ym = DATE_FORMAT(NOW(),'%Y-%m') UNION ALL select 0 AS cu_collection_rate -- 当期收缴率 ,0 AS pr_collection_rate -- 往期收缴率 ,0 AS pr_owed_amt -- 往期欠费金额 ,0 AS cu_owed_amt -- 当期欠费金额 ,a.thisy_paid_amt AS thisy_paid_amt -- 年度累计收费 ,b.thism_paid_amt AS thism_paid_amt -- 月度累计收费 from ( select '集团' tmp , sum(ifnull(pr_paid_cu_amt,0) + ifnull(cu_paid_cu_amt,0) - ifnull(cu_paid_pr_amt,0)) /10000 thisy_paid_amt , sum(case when ParentCostCode = '0008' and MiddleCostCode in ('00080001','00080002','00080003','00080004','00080005','00080006','00080007','00080008','00080009','00080010','00080011','00080012','00080017','00080018','00080019','00080020','00080021','00080022','00080023','00080024','00080027','00080028','00080032','00080034','00080035') then (ifnull(pr_paid_cu_amt,0) + ifnull(cu_paid_cu_amt,0) - ifnull(cu_paid_pr_amt,0) - ifnull(cu_paid_fu_amt,0)) else 0 end) /10000 thism_shuidian_paid_amt from dwd_finance_fees_serial_d a where ym = date_format(current_date(),'%Y-%m') and organ_name not in ('东湖商管','领悦总部','演示机构') and ParentCostCode not in ('0006','0009','0010','0011') and MiddleCostCode not in ('00080013','00080014','00080015','00080016','00080025','00080026','00080029','00080030','00080031','00080033','00080036','00080037') and commid not in(select comm_id from ods_remove_comm) )a left join ( select '集团' tmp , sum(ifnull(cu_paid_cu_amt,0) - ifnull(cu_paid_pr_amt,0)) /10000 thism_paid_amt from dwd_finance_total_paid_fees_m a where ym = date_format(current_date(),'%Y-%m') and organ_name not in ('东湖商管','领悦总部','演示机构') and ParentCostCode not in ('0006','0009','0010','0011') and MiddleCostCode not in ('00080013','00080014','00080015','00080016','00080025','00080029','00080033','00080036','00080037') and commid not in(select comm_id from ods_remove_comm) )b on a.tmp = b.tmp ) SELECT T.dt AS dt-- 前一天 ,T.extract_time AS extract_time-- 抽数时间 ,T.metric_name AS metric_name-- 指标名称 ,SUM(T.metric_value) AS metric_value -- 指标值 FROM ( SELECT DATE_ADD(CURRENT_DATE,INTERVAL -1 DAY) AS dt -- 前一天 ,CURRENT_TIMESTAMP AS extract_time -- 抽数时间 ,'当期收缴率' AS metric_name -- 指标名称 ,cu_collection_rate AS metric_value -- 指标值 FROM base_metric UNION ALL SELECT DATE_ADD(CURRENT_DATE,INTERVAL -1 DAY) AS dt -- 前一天 ,CURRENT_TIMESTAMP AS extract_time -- 抽数时间 ,'往期收缴率' AS metric_name -- 指标名称 ,pr_collection_rate AS metric_value -- 指标值 FROM base_metric UNION ALL SELECT DATE_ADD(CURRENT_DATE,INTERVAL -1 DAY) AS dt -- 前一天 ,CURRENT_TIMESTAMP AS extract_time -- 抽数时间 ,'往期欠费金额' AS metric_name -- 指标名称 ,pr_owed_amt AS metric_value -- 指标值 FROM base_metric UNION ALL SELECT DATE_ADD(CURRENT_DATE,INTERVAL -1 DAY) AS dt -- 前一天 ,CURRENT_TIMESTAMP AS extract_time -- 抽数时间 ,'当期欠费金额' AS metric_name -- 指标名称 ,cu_owed_amt AS metric_value -- 指标值 FROM base_metric UNION ALL SELECT DATE_ADD(CURRENT_DATE,INTERVAL -1 DAY) AS dt -- 前一天 ,CURRENT_TIMESTAMP AS extract_time -- 抽数时间 ,'年度累计收费' AS metric_name -- 指标名称 ,thisy_paid_amt AS metric_value -- 指标值 FROM base_metric UNION ALL SELECT DATE_ADD(CURRENT_DATE,INTERVAL -1 DAY) AS dt -- 前一天 ,CURRENT_TIMESTAMP AS extract_time -- 抽数时间 ,'月度累计收费' AS metric_name -- 指标名称 ,thism_paid_amt AS metric_value -- 指标值 FROM base_metric )T GROUP BY T.dt,T.extract_time,T.metric_name ; with base_date AS ( SELECT T.metric_name AS metric_name ,sum(T.yesterday_value) AS yesterday_value ,SUM(T.today_value) AS today_value FROM ( SELECT A.metric_name AS metric_name -- 指标名称 , 0 AS yesterday_value -- 昨日指标值 , A.metric_value AS today_value -- 今日指标值 FROM ( SELECT metric_name , metric_value , ROW_NUMBER() OVER (PARTITION BY metric_name,dt ORDER BY extract_time DESC) AS rk FROM ods_history_metric_save WHERE LEFT(dt, 10) = DATE_SUB('${s_ym}', INTERVAL 1 DAY)) A WHERE rk = 1 UNION ALL SELECT A.metric_name AS metric_name -- 指标名称 , A.metric_value AS yesterday_value -- 昨日指标值 , 0 AS today_value -- 今日指标值 FROM ( SELECT metric_name , metric_value , ROW_NUMBER() OVER (PARTITION BY metric_name,dt ORDER BY extract_time DESC) AS rk FROM ods_history_metric_save WHERE LEFT(dt, 10) = DATE_SUB('${s_ym}', INTERVAL 2 DAY) ) A WHERE rk = 1 )T GROUP BY T.metric_name ) SELECT metric_name ,yesterday_value AS yesterday_value ,today_value AS today_value ,CASE WHEN metric_name = '当期欠费金额' THEN (CASE WHEN today_value > yesterday_value THEN '1' ELSE '0' END) WHEN metric_name = '往期欠费金额' THEN (CASE WHEN today_value > yesterday_value THEN '1' ELSE '0' END) WHEN metric_name = '当期收缴率' THEN (CASE WHEN today_value < yesterday_value THEN '1' ELSE '0' END) WHEN metric_name = '往期收缴率' THEN (CASE WHEN today_value < yesterday_value THEN '1' ELSE '0' END) WHEN metric_name = '月度累计收费' THEN (CASE WHEN today_value < yesterday_value THEN '1' ELSE '0' END) WHEN metric_name = '年度累计收费' THEN (CASE WHEN today_value < yesterday_value THEN '1' ELSE '0' END) END AS is_exception -- 是否异常 1:是 0:否 ,CASE WHEN metric_name = '当期欠费金额' THEN '当日数据>昨日数据' WHEN metric_name = '往期欠费金额' THEN '当日数据>昨日数据' WHEN metric_name = '当期收缴率' THEN '当日数据<昨日数据' WHEN metric_name = '往期收缴率' THEN '当日数据<昨日数据' WHEN metric_name = '月度累计收费' THEN '当日数据<昨日数据' WHEN metric_name = '年度累计收费' THEN '当日数据<昨日数据' END AS exception_rule -- 异常条件 /* -- 异常指标规则: 3、当期欠费金额:当日数据>昨日数据时; 4、往期欠费金额:当日数据>昨日数据时; 5、当期收缴率:当日数据<昨日数据时; 6、往期收缴率:当日数据<昨日数据时; 7、月度累计收费:当日数据<昨日数据时; 8、年度累计收费:当日数据<昨日数据时; */ FROM base_date ORDER BY CASE WHEN metric_name = '当期欠费金额' THEN 1 WHEN metric_name = '往期欠费金额' THEN 2 WHEN metric_name = '当期收缴率' THEN 3 WHEN metric_name = '往期收缴率' THEN 4 WHEN metric_name = '月度累计收费' THEN 5 WHEN metric_name = '年度累计收费' THEN 6 END -- 测试数据