-- ***************************** -- 创建人员: 杨坤安 -- 创建时间: 2024-08-08 -- 功能描述: 看板数据预警-项目维度 -- ***************************** -- ------------------------------- -- 财务 -- ------------------------------- -- ------------------------------- -- 运营 -- ------------------------------- SELECT '运营' AS BUSINESS_TYPE -- 业务类型 ,organ_name AS ORGAN_NAME -- 片区名称 ,comm_name AS COMM_NAME -- 项目名称 ,'接房率低于80%的项目' AS INDICATOR_TYPE -- 指标类型 ,accept_num / room_num AS ACCEPT_NUM_RATE -- 接房率 FROM dw.dws_operation_room_park_info_d where accept_num / room_num < 0.8 and comm_name not like '%案场%' and comm_name not like '%撤%' UNION ALL SELECT '运营' AS BUSINESS_TYPE -- 业务类型 ,c.organ_name AS ORGAN_NAME -- 片区名称 ,c.comm_name AS COMM_NAME -- 项目名称 ,'计划即将到期项目' AS INDICATOR_TYPE -- 指标类型 ,count(1) AS PLAN_NUM -- 计划即将到期数量 FROM ( SELECT a.plan_level, jt.responsible_person1 , a.id, a.plan_status, a.input_date, a.end_date FROM dwd_operations_plan_info_d a, JSON_TABLE ( cast( CONCAT( '["', REPLACE ( responsible_person1, ',', '","' ), '"]' ) AS json ), "$[*]" COLUMNS ( responsible_person1 INT PATH "$" ) ) AS jt where a.end_date > date_format(CURDATE() - INTERVAL 3 day,'%Y-%m-%d') and a.end_date <= date_format(CURDATE(),'%Y-%m-%d') ) a left join dw.ods_oa_hrmresource_d b on a.responsible_person1 = b.id left join ( select distinct organ_code ,organ_name ,comm_id ,comm_name ,oa_comm_id from dim_organ_mapping where comm_id is not null )c on b.subcompanyid1 = c.oa_comm_id GROUP BY c.organ_name, c.comm_name UNION ALL select '运营' AS BUSINESS_TYPE -- 业务类型 ,organ_name AS ORGAN_NAME -- 片区名称 ,comm_name AS COMM_NAME -- 项目名称 ,'权责亏损项目-填报' AS INDICATOR_TYPE -- 指标类型 ,count(1) AS PROJECT_NUM -- 权责亏损项目数 from ods_caiwu_feecollection where yr_month = '2024-06' and category = '物业' and index_profit_fact < 0 GROUP BY organ_name, comm_name UNION ALL -- ------------------------------- -- 物业 -- ------------------------------- select '物业' AS BUSINESS_TYPE -- 业务类型 ,organ_name AS ORGAN_NAME -- 片区名称 ,comm_name AS COMM_NAME -- 项目名称 ,'物业费实收总额(万元)' AS INDICATOR_TYPE -- 指标类型 ,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)- ifnull(cu_offset_pr_amt,0) - ifnull(cu_paid_pr_amt,0))/10000 paid_amt from dw.dwd_finance_fees_serial_d where ParentCostCode = '0001' and left(ym,7) = left(CURRENT_DATE(),7) -- 当前月 and organ_name not in ('东湖商管','领悦总部','演示机构') GROUP BY organ_name, comm_name UNION ALL select '物业' AS BUSINESS_TYPE -- 业务类型 ,organ_name AS ORGAN_NAME -- 片区名称 ,comm_name AS COMM_NAME -- 项目名称 ,'物业费收缴率' AS INDICATOR_TYPE -- 指标类型 ,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)+(- ifnull(cu_paid_pr_amt,0) - ifnull(cu_offset_pr_amt,0))) / sum(ifnull(cu_receivable_amt,0) + ifnull(pr_exempt_cu_amt,0) + ifnull(cu_exempt_cu_amt,0)+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)) collection_rate from dwd_finance_fees_serial_d where ParentCostCode = '0001' AND left(ym,7) = left(CURRENT_DATE(),7) -- 当前月 GROUP BY organ_name, comm_name UNION ALL -- TODO SELECT '物业' AS BUSINESS_TYPE -- 业务类型 ,'' AS ORGAN_NAME -- 片区名称 ,'' AS COMM_NAME -- 项目名称 ,'案场服务费当期收缴率' AS INDICATOR_TYPE -- 指标类型 ,0 AS VALUE FROM dual UNION ALL SELECT '物业' AS BUSINESS_TYPE -- 业务类型 ,organ_name AS ORGAN_NAME -- 片区名称 ,comm_name AS COMM_NAME -- 项目名称 ,'投诉关闭率' AS INDICATOR_TYPE -- 指标类型 , sum(tousu_close_incident_num) / sum(tousu_incident_num) AS tousu_close_rate FROM dws_estate_incident_info_m where incident_ym = replace(left(CURRENT_DATE(),7),'-','') group BY organ_name, comm_name UNION ALL SELECT '物业' AS BUSINESS_TYPE -- 业务类型 ,organ_name AS ORGAN_NAME -- 片区名称 ,comm_name AS COMM_NAME -- 项目名称 ,'报事关闭率' AS INDICATOR_TYPE -- 指标类型 , sum(completed_incident_num - completed_not_close_incident_num) / sum(incident_num) AS close_rate FROM dws_estate_incident_info_m where incident_ym = replace(left(CURRENT_DATE(),7),'-','') group BY organ_name, comm_name UNION ALL -- ------------------------------- -- 工程 -- ------------------------------- SELECT '工程' AS BUSINESS_TYPE -- 业务类型 ,organ_name AS ORGAN_NAME -- 片区名称 ,comm_name AS COMM_NAME -- 项目名称 ,'水电收缴率' AS INDICATOR_TYPE -- 指标类型 ,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))+(- ifnull(cu_paid_pr_amt,0) - ifnull(cu_offset_pr_amt,0))) / sum((ifnull(cu_receivable_amt,0) + ifnull(pr_exempt_cu_amt,0) + ifnull(cu_exempt_cu_amt,0))+(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))) collection_rate from dwd_finance_fees_serial_d where ParentCostCode = '0008' and MiddleCostCode in ('00080001','00080002','00080003','00080004','00080005','00080006','00080007','00080008','00080017','00080018','00080019','00080022','00080023','00080024','00080027','00080028','00080032','00080035') and ym = left(CURRENT_DATE(),7) GROUP BY organ_name, comm_name UNION ALL SELECT '工程' AS BUSINESS_TYPE -- 业务类型 ,a.organ_name AS ORGAN_NAME -- 片区名称 ,a.comm_name AS COMM_NAME -- 项目名称 ,'停车场启费率-无法计算项目收缴率' AS INDICATOR_TYPE -- 指标类型 ,SUM(case when qifei_cost_num > 0 then 1 else 0 end) / sum(CNT) AS qifei_rate from ( select a.organ_name ,a.comm_name ,sum(case when (ifnull(pr_paid_cu_amt,0) + ifnull(cu_paid_cu_amt,0) + ifnull(pr_exempt_cu_amt,0) + ifnull(cu_exempt_cu_amt,0)) + (ifnull(cu_receivable_amt,0) + ifnull(pr_exempt_cu_amt,0) + ifnull(cu_exempt_cu_amt,0)) + (- ifnull(cu_paid_pr_amt,0) + ifnull(cu_offset_pr_amt,0)) + (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)) !=0 then 1 else 0 end) qifei_cost_num ,count(1) over() AS CNT from ( select distinct organ_code ,organ_name ,comm_id ,comm_name from dim_organ_mapping where comm_id is not null and comm_name not like '%撤场%' and comm_name not like '%案场%' and comm_name not like '%禁用%' and length(comm_id) != 0 )a left join ( select * from dwd_finance_fees_serial_d where MiddleCostCode in ('00010003','00030001','00030002','00030003','00030004','00030005','00030006','00030007','00030008','00030009','00030010') and ym = left(CURRENT_DATE(),7) )b on a.comm_id = b.commid group by a.organ_name, a.comm_name )a GROUP BY a.organ_name, a.comm_name UNION ALL SELECT '工程' AS BUSINESS_TYPE -- 业务类型 ,organ_name AS ORGAN_NAME -- 片区名称 ,comm_name AS COMM_NAME -- 项目名称 ,'设备设施完好率' AS INDICATOR_TYPE -- 指标类型 ,CASE WHEN sum(equipment_num) = 0 THEN 0 else sum(good_equipment_num) / sum(equipment_num) END AS good_rate FROM dws_engine_equipment_in_good_d GROUP BY organ_name, comm_name UNION ALL SELECT '工程' AS BUSINESS_TYPE -- 业务类型 ,organ_name AS ORGAN_NAME -- 片区名称 ,comm_name AS COMM_NAME -- 项目名称 ,'设备空间巡查完成率' AS INDICATOR_TYPE -- 指标类型 ,CASE WHEN SUM(task_num) = 0 THEN 0 ELSE SUM(task_finish_num) / SUM(task_num) END AS FINISH_RATE FROM dws_engine_equipment_inspect_task_m where task_ym = replace(left(CURRENT_DATE(),7),'-','') GROUP BY organ_name, comm_name UNION ALL SELECT '工程' AS BUSINESS_TYPE -- 业务类型 ,organ_name AS ORGAN_NAME -- 片区名称 ,comm_name AS COMM_NAME -- 项目名称 ,'异常抬杆比例' AS INDICATOR_TYPE -- 指标类型 ,CASE WHEN SUM(carflow) = 0 THEN 0 ELSE SUM(manualOutNum) / SUM(carflow) END AS exceptionRate from dws_engine_stat_exception_rate_w where yw = (select distinct yw from dws_engine_stat_exception_rate_w order by yw desc limit 1) GROUP BY organ_name, comm_name -- ------------------------------- -- 创新 => 没有项目 -- ------------------------------- UNION ALL -- ------------------------------- -- 商业 -- ------------------------------- -- ------------------------------- -- 法务 -- -------------------------------