From b4b656c681dc0064c0c1297c219b2db276c61309 Mon Sep 17 00:00:00 2001 From: yangkunan Date: Fri, 25 Oct 2024 15:13:36 +0800 Subject: [PATCH] =?UTF-8?q?=E4=BA=BA=E5=8A=9B=E7=9C=8B=E6=9D=BF=E6=8C=87?= =?UTF-8?q?=E6=A0=87=E7=AC=AC=E4=B8=80=E7=89=88?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- finereport/kanban/pc/人力.sql | 542 ++++++++++++++++++++++++++++++++++ 1 file changed, 542 insertions(+) diff --git a/finereport/kanban/pc/人力.sql b/finereport/kanban/pc/人力.sql index e69de29..14dec1e 100644 --- a/finereport/kanban/pc/人力.sql +++ b/finereport/kanban/pc/人力.sql @@ -0,0 +1,542 @@ +-- ====================================== +-- HR组织机构 +-- ====================================== + +WITH one_department AS( + + SELECT + id + ,subcompanyname + FROM ods_hr_hrmsubcompany_d + WHERE tlevel = '1' +), + sec_department AS + ( + SELECT + b.id AS one_department_code + ,b.subcompanyname AS one_department_name + ,a.id AS sec_department_code + ,a.subcompanyname AS sec_department_name + FROM + ( + SELECT + id + ,subcompanyname + ,supsubcomid + FROM ods_hr_hrmsubcompany_d + WHERE tlevel = '2' + )A + LEFT JOIN one_department B + ON A.supsubcomid = B.id + ), + third_department AS + ( + SELECT + b.one_department_code AS one_department_code + ,b.one_department_name AS one_department_name + ,b.sec_department_code AS sec_department_code + ,b.sec_department_name AS sec_department_name + ,a.id AS third_department_code + ,a.subcompanyname AS third_department_name + FROM + ( + SELECT + id + ,subcompanyname + ,supsubcomid + FROM ods_hr_hrmsubcompany_d + WHERE tlevel = '3' + )A + LEFT JOIN sec_department B + ON A.supsubcomid = B.sec_department_code + ) + +SELECT + one_department_code + ,one_department_name + ,sec_department_code + ,sec_department_name + ,third_department_code + ,third_department_name +FROM third_department +; + + +-- ====================================== +-- report_指标卡_在职人数 +-- ====================================== + +SELECT + SUM(sl) AS SL +FROM + ( + SELECT + pq + ,zb + ,xm + ,sl + FROM ods_hr_view_zaizhi_all_d -- 在职人数 + WHERE 1=1 + ${IF(LEN(p_area)>0," AND pq IN ('"+JOINARRAY(p_area,"','")+"')", "")} + + )A + JOIN + ( + SELECT + * + FROM ods_hr_hrmsubcompany_d + )B + ON A.pq = B.id + JOIN + ( + SELECT + * + FROM ods_hr_hrmsubcompany_d + )C + ON A.xm = C.id + +-- ====================================== +-- 指标卡_离职人数 +-- ====================================== + +SELECT + SUM(lzrs) AS SL +FROM + ( + SELECT + pq + ,zb + ,xm + ,lzrs + ,concat(nd,'-',yd) AS YM + FROM ods_hr_view_lzrs_d -- 离职人数 + WHERE concat(nd,'-',yd) = '${p_ym}' + ${IF(LEN(p_area)>0," AND pq IN ('"+JOINARRAY(p_area,"','")+"')", "")} + )A + JOIN + ( + SELECT + * + FROM ods_hr_hrmsubcompany_d + )B + ON A.pq = B.id + JOIN + ( + SELECT + * + FROM ods_hr_hrmsubcompany_d + )C + ON A.xm = C.id + + +-- ====================================== +-- 指标卡_人力成本 +-- ====================================== + + +SELECT + sum(A.total_fee) AS total_fee +FROM + ( + select + organ_name + ,sum(total_fee) AS total_fee + from dw.dws_cost_lc_summary_d + WHERE fee_type = '实际值' + AND concat(yearname,'-',monthname) = '${p_ym}' + GROUP BY + organ_name + )A + LEFT JOIN + ( + SELECT + id + ,subcompanyname + FROM ods_hr_hrmsubcompany_d + WHERE tlevel = '2' + GROUP BY + id + ,subcompanyname + )B + ON A.organ_name = B.subcompanyname +WHERE 1 = 1 + ${IF(LEN(p_area)>0," AND B.id IN ('"+JOINARRAY(p_area,"','")+"')", "")} + + +-- ====================================== +-- 指标卡_行政成本 +-- ====================================== + +SELECT + sum(A.total_fee) AS total_fee +FROM + ( + select + organ_name + ,sum(total_fee) AS total_fee + from dw.dws_cost_ac_summary_d + WHERE fee_type = '实际值' + AND concat(yearname,'-',monthname) = '${p_ym}' + GROUP BY + organ_name + )A + LEFT JOIN + ( + SELECT + id + ,subcompanyname + FROM ods_hr_hrmsubcompany_d + WHERE tlevel = '2' + GROUP BY + id + ,subcompanyname + )B + ON A.organ_name = B.subcompanyname +WHERE 1 = 1 + ${IF(LEN(p_area)>0," AND B.id IN ('"+JOINARRAY(p_area,"','")+"')", "")} + +-- ====================================== +-- 员工满编率柱状图 +-- ====================================== +SELECT + nd -- 年度 + ,jd -- 季度 + ,yd -- 月度 + ,rq -- 日期 + ,zb -- 总部 + ,pq -- 片区 + ,xm -- 项目 + ,zzs -- 在职数 + ,bzs -- 编制数 + ,datediff(current_date(),rq) AS datedif -- 结束日期--开始日期 + ,sum(zzs) over(PARTITION BY rq,pq,xm) AS total_zzs -- 累计在职人数 + ,sum(bzs) over(PARTITION BY rq,pq,xm) AS total_bzs -- 累计编制人数 + ,sum(zzs) over(PARTITION BY rq,pq,xm) / datediff(current_date(),rq) AS avg_zzs -- 平均在职人数 + ,sum(bzs) over(PARTITION BY rq,pq,xm) / datediff(current_date(),rq) AS avg_bzs -- 平均编制人数 + ,CASE WHEN sum(bzs) over(PARTITION BY rq,pq,xm) / datediff(current_date(),rq) = 0 THEN 0 + ELSE (sum(zzs) over(PARTITION BY rq,pq,xm) / datediff(current_date(),rq)) / (sum(bzs) over(PARTITION BY rq,pq,xm) / datediff(current_date(),rq)) + END as rate +FROM ods_hr_view_mbl_d +WHERE 1 = 1 + ${IF(LEN(p_area)>0," AND pq IN ('"+JOINARRAY(p_area,"','")+"')", "")} + + +-- ====================================== +-- 员工满编率排名 +-- ====================================== + +SELECT + T.subcompanyname AS subcompanyname + ,ROW_NUMBER() OVER(ORDER BY T.RATE DESC) 排名 + ,T.RATE + ,'0' AS TARGET_RATE +FROM + ( + SELECT + ${IF(LEN(p_area)>0,"c.subcompanyname", "b.subcompanyname")} + ,CASE WHEN SUM(avg_bzs) = 0 THEN 0 ELSE SUM(avg_zzs) / SUM(avg_bzs) END AS RATE + FROM + ( + SELECT + + pq -- 片区 + ,xm -- 项目 + ,zzs -- 在职数 + ,bzs -- 编制数 + ,rq + ,datediff(current_date(),rq) AS datedif -- 结束日期--开始日期 + ,sum(zzs) over(PARTITION BY rq,pq,xm) AS total_zzs -- 累计在职人数 + ,sum(bzs) over(PARTITION BY rq,pq,xm) AS total_bzs -- 累计编制人数 + ,sum(zzs) over(PARTITION BY rq,pq,xm) / datediff(current_date(),rq) AS avg_zzs -- 平均在职人数 + ,sum(bzs) over(PARTITION BY rq,pq,xm) / datediff(current_date(),rq) AS avg_bzs -- 平均编制人数 + FROM ods_hr_view_mbl_d + WHERE CONCAT(nd,'-',yd) = '${p_ym}' + ${IF(LEN(p_area)>0," AND pq IN ('"+JOINARRAY(p_area,"','")+"')", "")} + )A + LEFT JOIN + ( + SELECT + id + ,subcompanyname + FROM ods_hr_hrmsubcompany_d + )B + ON A.pq = B.id + LEFT JOIN + ( + SELECT + id + ,subcompanyname + FROM ods_hr_hrmsubcompany_d + )C + ON A.xm = C.id + GROUP BY ${IF(LEN(p_area)>0,"c.subcompanyname", "b.subcompanyname")} + )T + + +-- ====================================== +-- 员工离职原因占比 +-- ====================================== + +SELECT + nd -- 年度 + ,jd -- 季度 + ,yd -- 月度 + ,rq -- 日期 + ,zb -- 总部 + ,pq -- 片区 + ,xm -- 项目 + ,lzlx -- 离职类型id + ,lzlxname -- 离职类型名称 + ,lzyy -- 离职原因id + ,lzyyname -- 离职原因名称 + ,lzrs -- 离职人数 +FROM ods_hr_view_lzrs_fl_d +WHERE LEFT(rq,7) = '${p_ym}' + ${IF(LEN(p_area)>0," AND pq IN ('"+JOINARRAY(p_area,"','")+"')", "")} + + +-- ====================================== +-- 人力行政成本费率柱状图 +-- ====================================== + +${if(p_type='人力',"","/*")} +SELECT + T1.yr_month AS yr_month + ,'人力成本' AS name + ,'人力成本费率' AS name_rate + ,RIGHT(T1.yr_month,2) AS MONTHS + ,T1.actual_cost AS actual_cost -- 人力成本 + ,T1.index_income_fact AS index_income_fact -- 实际收入 + ,T1.actual_cost / T1.index_income_fact AS FEE_RATE -- 费率 +FROM +( + SELECT + A.yr_month AS yr_month + ,A.actual_cost + ,b.index_income_fact AS index_income_fact + FROM + ( +-- 费控人力成本科目汇总表 + SELECT + organ_name + ,CONCAT(yearname,'-',monthname) AS yr_month + ,SUM(CASE WHEN fee_type IN('实际值','目标值') THEN total_fee ELSE 0 END) / 10000 AS actual_cost -- 人力成本 + from dw.dws_cost_ac_summary_d + WHERE yearname = left('${p_ym}',4) + AND CONCAT(yearname,'-',monthname) < '${p_ym}' + GROUP BY CONCAT(yearname,'-',monthname),organ_name + )A + LEFT JOIN + (-- 公司实际收入 + SELECT + yr_month + ,organ_name + ,SUM(index_income_fact) AS index_income_fact -- 实际收入 + FROM ods_caiwu_feecollection + WHERE category = '物业' + AND LEFT(yr_month,4) = left('${p_ym}',4) + GROUP BY yr_month,organ_name + )B + ON A.yr_month = B.yr_month + AND A.organ_name = B.organ_name + LEFT JOIN + ( + SELECT + id + ,subcompanyname + FROM ods_hr_hrmsubcompany_d + WHERE tlevel = '2' + GROUP BY + id + ,subcompanyname + )C + ON A.organ_name = C.subcompanyname + WHERE 1=1 + ${IF(LEN(p_area)>0," AND C.id IN ('"+JOINARRAY(p_area,"','")+"')", "")} + +)T1 +ORDER BY T1.yr_month +${if(p_type='人力',"","*/")} + +${if(p_type='行政',"","/*")} + +SELECT + T1.yr_month AS yr_month + ,'行政成本' AS name + ,'行政成本费率' AS name_rate + ,RIGHT(T1.yr_month,2) AS MONTHS + ,T1.actual_cost AS actual_cost -- 人力成本 + ,T1.index_income_fact AS index_income_fact -- 实际收入 + ,T1.actual_cost / T1.index_income_fact AS FEE_RATE -- 费率 +FROM +( + SELECT + A.yr_month AS yr_month + ,A.actual_cost AS actual_cost -- 人力成本 + ,B.index_income_fact AS index_income_fact -- 实际收入 + FROM + ( +-- 费控人力成本科目汇总表 + SELECT + organ_name + ,CONCAT(yearname, '-', monthname) AS yr_month + ,SUM(CASE WHEN fee_type IN ('实际值', '目标值') THEN total_fee ELSE 0 END) / 10000 AS actual_cost -- 人力成本 + FROM dw.dws_cost_lc_summary_d + WHERE yearname = LEFT('${p_ym}', 4) + AND CONCAT(yearname, '-', monthname) < '${p_ym}' + GROUP BY CONCAT(yearname, '-', monthname),organ_name + ) A + LEFT JOIN + (-- 公司实际收入 + SELECT + yr_month + ,organ_name + , SUM(index_income_fact) AS index_income_fact -- 实际收入 + FROM ods_caiwu_feecollection + WHERE category = '物业' + AND LEFT(yr_month, 4) = LEFT('${p_ym}', 4) + GROUP BY yr_month,organ_name + )B + ON A.yr_month = B.yr_month + AND A.organ_name = B.organ_name + LEFT JOIN + ( + SELECT + id + ,subcompanyname + FROM ods_hr_hrmsubcompany_d + WHERE tlevel = '2' + GROUP BY + id + ,subcompanyname + )C + ON A.organ_name = C.subcompanyname + WHERE 1=1 + ${IF(LEN(p_area)>0," AND C.id IN ('"+JOINARRAY(p_area,"','")+"')", "")} +)T1 +ORDER BY T1.yr_month + +${if(p_type='行政',"","*/")} + + +-- ====================================== +-- 人力行政成本费率排名 +-- ====================================== + + + +${if(p_type='人力',"","/*")} + + SELECT + A.organ_comm_name AS organ_comm_name + ,A.actual_cost AS actual_cost -- 成本 + ,B.index_income_fact AS index_income_fact -- 实际收入 + ,ROW_NUMBER() OVER (ORDER BY A.actual_cost / B.index_income_fact DESC ) AS 排名 -- 费率排名 + ,A.actual_cost / B.index_income_fact AS fee_rate -- 费率 + ,A.budget_actual_cost / B.index_income_target AS target_fee_rate -- 费率目标 + FROM + ( +-- 费控人力成本科目汇总表 + SELECT + ${IF(LEN(p_area)>0,"dimsubjectname", "organ_name")} AS organ_comm_name + ,SUM(CASE WHEN fee_type IN('实际值','目标值') THEN total_fee ELSE 0 END) / 10000 AS actual_cost -- 人力成本 + ,SUM(CASE WHEN fee_type = '目标值' THEN total_fee ELSE 0 END) / 10000 AS budget_actual_cost -- 人力成本预算值 + + FROM + ( + SELECT + * + FROM dw.dws_cost_ac_summary_d + WHERE CONCAT(yearname,'-',monthname) = '${LEFT(MONTHDELTA(p_ym,-1),7)}' + )A1 + LEFT JOIN + ( + SELECT + id + ,subcompanyname + FROM ods_hr_hrmsubcompany_d + WHERE tlevel = '2' + GROUP BY + id + ,subcompanyname + )A2 + ON A1.organ_name = A2.subcompanyname + WHERE 1=1 + ${IF(LEN(p_area)>0," AND A2.id IN ('"+JOINARRAY(p_area,"','")+"')", "")} + GROUP BY + ${IF(LEN(p_area)>0,"dimsubjectname", "organ_name")} + )A + LEFT JOIN + (-- 公司实际收入 + SELECT + ${IF(LEN(p_area)>0,"comm_name", "organ_name")} AS organ_comm_name + ,SUM(index_income_fact) AS index_income_fact -- 实际收入 + ,SUM(index_income_target) AS index_income_target -- 收入目标 + FROM ods_caiwu_feecollection + WHERE category = '物业' + AND yr_month = '${LEFT(MONTHDELTA(p_ym,-1),7)}' + GROUP BY + ${IF(LEN(p_area)>0,"comm_name", "organ_name")} + )B + ON A.organ_comm_name = B.organ_comm_name + +${if(p_type='人力',"","*/")} + +${if(p_type='行政',"","/*")} + + + +SELECT + A.organ_comm_name AS organ_comm_name + ,A.actual_cost AS actual_cost -- 成本 + ,B.index_income_fact AS index_income_fact -- 实际收入 + ,ROW_NUMBER() OVER (ORDER BY A.actual_cost / B.index_income_fact DESC ) AS 排名 -- 费率排名 + ,A.actual_cost / B.index_income_fact AS fee_rate -- 费率 + ,A.budget_actual_cost / B.index_income_target AS target_fee_rate -- 费率目标 +FROM + ( +-- 费控人力成本科目汇总表 + SELECT + ${IF(LEN(p_area)>0,"dimsubjectname", "organ_name")} AS organ_comm_name + ,SUM(CASE WHEN fee_type IN('实际值','目标值') THEN total_fee ELSE 0 END) / 10000 AS actual_cost -- 人力成本 + ,SUM(CASE WHEN fee_type = '目标值' THEN total_fee ELSE 0 END) / 10000 AS budget_actual_cost -- 人力成本预算值 + + FROM + ( + SELECT + * + FROM dw.dws_cost_lc_summary_d + WHERE CONCAT(yearname,'-',monthname) = '${LEFT(MONTHDELTA(p_ym,-1),7)}' + )A1 + LEFT JOIN + ( + SELECT + id + ,subcompanyname + FROM ods_hr_hrmsubcompany_d + WHERE tlevel = '2' + GROUP BY + id + ,subcompanyname + )A2 + ON A1.organ_name = A2.subcompanyname + WHERE 1=1 + ${IF(LEN(p_area)>0," AND A2.id IN ('"+JOINARRAY(p_area,"','")+"')", "")} + GROUP BY + ${IF(LEN(p_area)>0,"dimsubjectname", "organ_name")} + )A + LEFT JOIN + (-- 公司实际收入 + SELECT + ${IF(LEN(p_area)>0,"comm_name", "organ_name")} AS organ_comm_name + ,SUM(index_income_fact) AS index_income_fact -- 实际收入 + ,SUM(index_income_target) AS index_income_target -- 收入目标 + FROM ods_caiwu_feecollection + WHERE category = '物业' + AND yr_month = '${LEFT(MONTHDELTA(p_ym,-1),7)}' + GROUP BY + ${IF(LEN(p_area)>0,"comm_name", "organ_name")} + )B + ON A.organ_comm_name = B.organ_comm_name + + ${if(p_type='行政',"","*/")} \ No newline at end of file