From a6c38d853af6dea2d6ab1b86721747dd045673ee Mon Sep 17 00:00:00 2001 From: yangkunan Date: Mon, 18 Nov 2024 18:47:17 +0800 Subject: [PATCH] =?UTF-8?q?=E4=BD=8F=E6=9C=8D=E6=AF=94=E5=BC=82=E5=B8=B8?= =?UTF-8?q?=E4=BA=BA=E5=8A=9B=E7=9B=B8=E5=85=B3=E6=8C=87=E6=A0=87+x?= =?UTF-8?q?=E8=BD=B4=E6=97=B6=E9=97=B4=E6=98=BE=E7=A4=BA=E4=BC=98=E5=8C=96?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- finereport/kanban/mobile/人力_mobile.sql | 2 + finereport/kanban/pc/人力.sql | 2 + .../xiazuan/2_operation/住服比异常项目.sql | 224 +++++++++++++++++- 3 files changed, 222 insertions(+), 6 deletions(-) diff --git a/finereport/kanban/mobile/人力_mobile.sql b/finereport/kanban/mobile/人力_mobile.sql index 88ca789..8806437 100644 --- a/finereport/kanban/mobile/人力_mobile.sql +++ b/finereport/kanban/mobile/人力_mobile.sql @@ -1820,6 +1820,7 @@ ${IF(LEN(p_area)>0,"", "*/")} ${if(p_type='人力',"","/*")} SELECT T1.yr_month AS yr_month + ,CONCAT(right(T1.yr_month,2),'月') as m ,'人力成本' AS name ,'人力成本费率' AS name_rate ,T1.lc_total_fee AS total_fee -- 人力成本 @@ -1915,6 +1916,7 @@ ${if(p_type='人力',"","*/")} ${if(p_type='行政',"","/*")} SELECT T1.yr_month AS yr_month + ,CONCAT(right(T1.yr_month,2),'月') as m ,'行政成本' AS name ,'行政成本费率' AS name_rate ,T1.ac_total_fee AS total_fee -- 行政成本 diff --git a/finereport/kanban/pc/人力.sql b/finereport/kanban/pc/人力.sql index cb47938..643b7a7 100644 --- a/finereport/kanban/pc/人力.sql +++ b/finereport/kanban/pc/人力.sql @@ -957,6 +957,7 @@ with one_to_many AS( ) SELECT T1.yr_month AS yr_month + ,CONCAT(right(T1.yr_month,2),'月') as m ,'人力成本' AS name ,'人力成本费率' AS name_rate ,T1.lc_total_fee AS total_fee -- 人力成本 @@ -1063,6 +1064,7 @@ with one_to_many AS( ) SELECT T1.yr_month AS yr_month + ,CONCAT(right(T1.yr_month,2),'月') as m ,'行政成本' AS name ,'行政成本费率' AS name_rate ,T1.ac_total_fee AS total_fee -- 行政成本 diff --git a/finereport/xiazuan/2_operation/住服比异常项目.sql b/finereport/xiazuan/2_operation/住服比异常项目.sql index d7a1655..f6087bf 100644 --- a/finereport/xiazuan/2_operation/住服比异常项目.sql +++ b/finereport/xiazuan/2_operation/住服比异常项目.sql @@ -1,3 +1,7 @@ +-- 片区 + + +${if(len(p_area) = 0,"","/*")} with one_to_many AS( SELECT a.username AS username -- 用户名 @@ -6,9 +10,187 @@ FROM ods_one_to_many_perm a JOIN mysql.help_topic b on b.help_topic_id < (LENGTH(a.mang_project) - length(replace(a.mang_project,',','')) + 1) WHERE a.username = '${fine_username}' +),hr_date AS +( + + +SELECT + B.organ_code AS organ_code +,B.organ_name AS organ_name +,SUM(A.bzs) AS bzs +,SUM(zzs) AS zzs -- 在职人数 +FROM +( + SELECT + A1.pq AS pq + ,SUM(A1.zzs) AS zzs + ,sum(A1.bzs) AS bzs + FROM + ( + SELECT + pq -- 片区 + ,ny + ,SUM(zzs) AS zzs -- 在职数 + ,SUM(bzs) AS bzs -- 编制数 + FROM ods_hr_view_mbl_d + WHERE pq not in('89','267') -- 排除了佳美、悦汇 + and ny > '2024-10' + GROUP BY pq,ny,xm + UNION ALL + SELECT + organ_code as pq + ,concat(left(ym,4),'-',right(ym,2)) as ny + ,SUM(zzs) AS zzs + ,SUM(bzs) AS bzs + FROM ods_hr_history_bz_num + WHERE 1 = 1 + GROUP BY ym,organ_code + )A1 + WHERE A1.ny = '${p_startdate}' + group by A1.pq +)A +RIGHT JOIN +( + SELECT + organ_code -- erp片区编码 + ,organ_name -- erp片区名称 + ,hr_organ_id -- hr片区编码 + ,hr_organ_name -- hr片区名称 + FROM dim_organ_mapping + WHERE length(hr_organ_id) > 0 + GROUP BY + organ_code + ,organ_name + ,hr_organ_id + ,hr_organ_name +)B +ON A.pq = B.hr_organ_id +group by B.organ_code, B.organ_name + ) select - ${if(len(p_area) == 0,"organ_name","comm_name")} as p_area -- 片区/项目 + a.organ_name as p_area -- 片区/项目 + ,sum(room_num) as room_num -- 房间总数 【总户数】 + ,sum(check_ins_num) as check_ins_num -- 入住数 【入住户数】 + ,case when sum(check_ins_num) = 0 + then 0 + else sum(check_ins_num) / sum(room_num) + end as occupancy_rate -- 入住率 + ,SUM(IFNULL(b.zzs,0)) AS zzs -- 在职数 + ,SUM(ifnull(b.bzs,0)) AS bzs -- 编制数 + ,CASE WHEN SUM(b.bzs) = 0 THEN 0 ELSE SUM(b.zzs) / SUM(b.bzs) END AS full_rate -- 满编率 +from +( + SELECT + organ_code + ,organ_name + ,SUM(room_num) AS room_num + ,SUM(check_ins_num) AS check_ins_num + FROM dws_operation_room_park_info_d + WHERE 1 = 1 +-- ${if(left(fine_role,2)=="项目","and comm_name = '"+GETUSERDEPARTMENTS(3)+"'","")} +AND CASE WHEN (SELECT mang_project FROM ods_one_to_many_perm WHERE username = '${fine_username}' AND mang_organ IS NULL) IS NOT NULL + THEN comm_name IN (SELECT mang_project FROM one_to_many WHERE username = '${fine_username}') + ELSE ${if(left(fine_role,2)=="项目","comm_name = '"+GETUSERDEPARTMENTS(3)+"'","1=1")} END + + group by + organ_code + ,organ_name +) a +left join hr_date b +on a.organ_code = b.organ_code + +group by +a.organ_name + +${if(len(p_area) = 0,"","*/")} + + +-- 项目 + +${if(len(p_area) > 0,"","/*")} +with one_to_many AS( +SELECT +a.username AS username -- 用户名 +,SUBSTRING_INDEX(SUBSTRING_INDEX(a.mang_project, ',',b.help_topic_id + 1),',',-1) AS mang_project -- 管理项目名 +FROM ods_one_to_many_perm a +JOIN mysql.help_topic b +on b.help_topic_id < (LENGTH(a.mang_project) - length(replace(a.mang_project,',','')) + 1) +WHERE a.username = '${fine_username}' +),hr_date AS +( + + +SELECT + B.organ_code AS organ_code +,B.organ_name AS organ_name +,B.comm_id AS comm_id +,B.comm_name AS comm_name +,SUM(A.bzs) AS bzs +,SUM(zzs) AS zzs -- 在职人数 +FROM +( + SELECT + A1.pq AS pq + ,A1.xm AS xm + ,SUM(A1.zzs) AS zzs + ,sum(A1.bzs) AS bzs + FROM + ( + SELECT + pq -- 片区 + ,ny + ,xm + ,SUM(zzs) AS zzs -- 在职数 + ,SUM(bzs) AS bzs -- 编制数 + FROM ods_hr_view_mbl_d + WHERE pq not in('89','267') -- 排除了佳美、悦汇 + GROUP BY pq,ny,xm + -- 没有项目的历史数据 + -- UNION ALL + -- SELECT + -- organ_code as pq + -- ,concat(left(ym,4),'-',right(ym,2)) as ny + -- ,'' AS xm + -- ,SUM(zzs) AS zzs + -- ,SUM(bzs) AS bzs + -- FROM ods_hr_history_bz_num + -- WHERE 1 = 1 + -- GROUP BY ym,organ_code + )A1 + WHERE A1.ny = '${p_startdate}' + group by A1.pq,A1.xm +)A +RIGHT JOIN +( + SELECT + organ_code -- erp片区编码 + ,organ_name -- erp片区名称 + ,hr_organ_id -- hr片区编码 + ,hr_organ_name -- hr片区名称 + ,hr_comm_id -- hr项目id + ,hr_comm_name -- hr项目名称 + ,comm_id + ,comm_name + FROM dim_organ_mapping + WHERE length(hr_comm_id) > 0 + GROUP BY + organ_code + ,organ_name + ,hr_organ_id + ,hr_organ_name + ,hr_comm_id + ,hr_comm_name + ,comm_id + ,comm_name +)B +ON A.pq = B.hr_organ_id +AND A.xm = B.hr_comm_id +group by B.organ_code, B.organ_name, B.comm_id, B.comm_name + +) +select + a.comm_name as p_area -- 片区/项目 -- organ_name -- 片区名称 -- ,comm_name -- 项目名称 ,sum(room_num) as room_num -- 房间总数 【总户数】 @@ -17,13 +199,43 @@ select then 0 else sum(check_ins_num) / sum(room_num) end as occupancy_rate -- 入住率 -from dws_operation_room_park_info_d -where 1=1 -${IF(LEN(p_area)!=0," and organ_code IN ('"+p_area+"')","")} + ,SUM(IFNULL(b.zzs,0)) AS zzs -- 在职数 + ,SUM(ifnull(b.bzs,0)) AS bzs -- 编制数 + ,CASE WHEN SUM(b.bzs) = 0 THEN 0 ELSE SUM(b.zzs) / SUM(b.bzs) END AS full_rate -- 满编率 +from +( + SELECT + organ_code + ,organ_name + ,comm_id + ,comm_name + ,SUM(room_num) AS room_num + ,SUM(check_ins_num) AS check_ins_num + FROM dws_operation_room_park_info_d + WHERE 1 = 1 -- ${if(left(fine_role,2)=="项目","and comm_name = '"+GETUSERDEPARTMENTS(3)+"'","")} AND CASE WHEN (SELECT mang_project FROM ods_one_to_many_perm WHERE username = '${fine_username}' AND mang_organ IS NULL) IS NOT NULL - THEN comm_name IN (SELECT mang_project FROM one_to_many WHERE username = '${fine_username}') + THEN comm_name IN (SELECT mang_project FROM one_to_many WHERE username = '${fine_username}') ELSE ${if(left(fine_role,2)=="项目","comm_name = '"+GETUSERDEPARTMENTS(3)+"'","1=1")} END + group by + organ_code + ,organ_name + ,comm_id + ,comm_name +) a +left join hr_date b +on a.organ_code = b.organ_code +and a.comm_id = b.comm_id +where 1=1 +${IF(LEN(p_area)!=0," and a.organ_code IN ('"+p_area+"')","")} +-- ${if(left(fine_role,2)=="项目","and comm_name = '"+GETUSERDEPARTMENTS(3)+"'","")} +AND CASE WHEN (SELECT mang_project FROM ods_one_to_many_perm WHERE username = '${fine_username}' AND mang_organ IS NULL) IS NOT NULL + THEN a.comm_name IN (SELECT mang_project FROM one_to_many WHERE username = '${fine_username}') + ELSE ${if(left(fine_role,2)=="项目","a.comm_name = '"+GETUSERDEPARTMENTS(3)+"'","1=1")} END + group by -${if(len(p_area) == 0,"organ_name","comm_name")} \ No newline at end of file +a.comm_name + + +${if(len(p_area) > 0,"","*/")} \ No newline at end of file