DROP TABLE IF EXISTS dw.dws_cost_ac_summary_d; CREATE TABLE IF NOT EXISTS dw.dws_cost_ac_summary_d ( yearname VARCHAR(50) COMMENT '年' ,monthname VARCHAR(50) COMMENT '月' ,organ_code VARCHAR(255) COMMENT '片区ID' ,organ_name VARCHAR(255) COMMENT '片区名称' ,dimsubjectcode VARCHAR(255) COMMENT '组织机构编码' ,dimsubjectname VARCHAR(255) COMMENT '组织机构名称' ,office_rent VARCHAR(255) COMMENT '办公室租金' ,office_repair_fee VARCHAR(255) COMMENT '办公维修费' ,office_fee VARCHAR(255) COMMENT '办公费' ,travel_fee VARCHAR(255) COMMENT '差旅费' ,phone_fee VARCHAR(255) COMMENT '电话费' ,ad_fee VARCHAR(255) COMMENT '广告宣传费' ,business_fee VARCHAR(255) COMMENT '业务接待费' ,water_power_fee VARCHAR(255) COMMENT '水电费' ,management_fee VARCHAR(255) COMMENT '物管费' ,book_fee VARCHAR(255) COMMENT '书报资料费' ,other_fee VARCHAR(255) COMMENT '其他费用' ,total_fee VARCHAR(255) COMMENT '当期小计' ,fee_type VARCHAR(50) COMMENT '费用类型' )COMMENT = '费控人力成本科目汇总表' INSERT into dw.dws_cost_ac_summary_d SELECT A.yearname AS yearname -- 年 ,A.monthname AS monthname -- 月 ,A.organ_code AS organ_code -- 片区ID ,A.organ_name AS organ_name -- 片区名称 ,A.dimsubjectcode AS dimsubjectcode -- 组织机构编码 ,A.dimsubjectname AS dimsubjectname -- 组织机构名称 ,SUM(A.salary_fee) AS salary_fee -- 工资 ,SUM(A.year_performance_fee) AS year_performance_fee -- 季度/年终绩效 ,SUM(A.social_insur_fee) AS social_insur_fee -- 社会保险 ,SUM(A.accumu_fund_fee) AS accumu_fund_fee -- 公积金 ,SUM(A.liab_insur_fee) AS liab_insur_fee -- 雇主责任险 ,SUM(A.smock_fee) AS smock_fee -- 工作服 ,SUM(A.train_fee) AS train_fee -- 培训 ,SUM(A.recr_fee) AS recr_fee -- 招聘 ,SUM(A.emp_bene_fee) AS emp_bene_fee -- 员工福利 ,SUM(A.laborrela_fee) AS laborrela_fee -- 劳动关系成本 ,SUM(A.other_fee) AS other_fee -- 其他费用 ,SUM(A.total_fee) AS total_fee -- 当期小计 ,A.fee_type AS fee_type -- 费用类型 FROM ( SELECT yearname -- 年 ,monthname -- 月 ,organ_code -- 片区ID ,organ_name -- 片区名称 ,dimsubjectcode -- 组织机构编码 ,dimsubjectname -- 组织机构名称 ,CASE WHEN dimaccountcode = 'WY040101' THEN target_fee ELSE 0 END AS salary_fee -- 工资 ,CASE WHEN dimaccountcode = 'WY040102' THEN target_fee ELSE 0 END AS year_performance_fee-- 季度/年终绩效 ,CASE WHEN dimaccountcode = 'WY040104' THEN target_fee ELSE 0 END AS social_insur_fee -- 社会保险 ,CASE WHEN dimaccountcode = 'WY040109' THEN target_fee ELSE 0 END AS accumu_fund_fee -- 公积金 ,CASE WHEN dimaccountcode = 'WY040112' THEN target_fee ELSE 0 END AS liab_insur_fee -- 雇主责任险 ,CASE WHEN dimaccountcode = 'WY040111' THEN target_fee ELSE 0 END AS smock_fee -- 工作服 ,CASE WHEN dimaccountcode = 'WY040107' THEN target_fee ELSE 0 END AS train_fee -- 培训 ,CASE WHEN dimaccountcode = 'WY040110' THEN target_fee ELSE 0 END AS recr_fee -- 招聘 ,CASE WHEN dimaccountcode = 'WY040103' THEN target_fee ELSE 0 END AS emp_bene_fee -- 员工福利 ,CASE WHEN dimaccountcode IN('WY040108','') -- 离职员工补偿 THEN target_fee ELSE 0 END AS laborrela_fee -- 劳动关系成本 ,CASE WHEN dimaccountcode in('WY040105','WY040114','WY040106','WY040113') -- 工会经费,残疾人保障金,职工教育经费,汽车费 THEN target_fee ELSE 0 END AS other_fee -- 其他费用 ,target_fee AS total_fee -- 当期小计 ,'目标值' AS fee_type -- 费用类型 from dw.dwd_cost_detail_data_d where cost_code = 'AC' -- 人力成本 UNION ALL SELECT yearname -- 年 ,monthname -- 月 ,organ_code -- 片区ID ,organ_name -- 片区名称 ,dimsubjectcode -- 组织机构编码 ,dimsubjectname -- 组织机构名称 ,CASE WHEN dimaccountcode = 'WY040101' THEN actual_fee ELSE 0 END AS salary_fee -- 工资 ,CASE WHEN dimaccountcode = 'WY040102' THEN actual_fee ELSE 0 END AS year_performance_fee-- 季度/年终绩效 ,CASE WHEN dimaccountcode = 'WY040104' THEN actual_fee ELSE 0 END AS social_insur_fee -- 社会保险 ,CASE WHEN dimaccountcode = 'WY040109' THEN actual_fee ELSE 0 END AS accumu_fund_fee -- 公积金 ,CASE WHEN dimaccountcode = 'WY040112' THEN actual_fee ELSE 0 END AS liab_insur_fee -- 雇主责任险 ,CASE WHEN dimaccountcode = 'WY040111' THEN actual_fee ELSE 0 END AS smock_fee -- 工作服 ,CASE WHEN dimaccountcode = 'WY040107' THEN actual_fee ELSE 0 END AS train_fee -- 培训 ,CASE WHEN dimaccountcode = 'WY040110' THEN actual_fee ELSE 0 END AS recr_fee -- 招聘 ,CASE WHEN dimaccountcode = 'WY040103' THEN actual_fee ELSE 0 END AS emp_bene_fee -- 员工福利 ,CASE WHEN dimaccountcode IN('WY040108','') -- 离职员工补偿 THEN actual_fee ELSE 0 END AS laborrela_fee -- 劳动关系成本 ,CASE WHEN dimaccountcode in('WY040105','WY040114','WY040106','WY040113') -- 工会经费,残疾人保障金,职工教育经费,汽车费 THEN actual_fee ELSE 0 END AS other_fee -- 其他费用 ,actual_fee AS total_fee -- 当期小计 ,'实际值' AS fee_type -- 费用类型 from dw.dwd_cost_detail_data_d where cost_code = 'AC' -- 人力成本 UNION ALL SELECT yearname -- 年 ,monthname -- 月 ,organ_code -- 片区ID ,organ_name -- 片区名称 ,dimsubjectcode -- 组织机构编码 ,dimsubjectname -- 组织机构名称 ,CASE WHEN dimaccountcode = 'WY040101' THEN diff_amount ELSE 0 END AS salary_fee -- 工资 ,CASE WHEN dimaccountcode = 'WY040102' THEN diff_amount ELSE 0 END AS year_performance_fee-- 季度/年终绩效 ,CASE WHEN dimaccountcode = 'WY040104' THEN diff_amount ELSE 0 END AS social_insur_fee -- 社会保险 ,CASE WHEN dimaccountcode = 'WY040109' THEN diff_amount ELSE 0 END AS accumu_fund_fee -- 公积金 ,CASE WHEN dimaccountcode = 'WY040112' THEN diff_amount ELSE 0 END AS liab_insur_fee -- 雇主责任险 ,CASE WHEN dimaccountcode = 'WY040111' THEN diff_amount ELSE 0 END AS smock_fee -- 工作服 ,CASE WHEN dimaccountcode = 'WY040107' THEN diff_amount ELSE 0 END AS train_fee -- 培训 ,CASE WHEN dimaccountcode = 'WY040110' THEN diff_amount ELSE 0 END AS recr_fee -- 招聘 ,CASE WHEN dimaccountcode = 'WY040103' THEN diff_amount ELSE 0 END AS emp_bene_fee -- 员工福利 ,CASE WHEN dimaccountcode IN('WY040108') -- 离职员工补偿 THEN diff_amount ELSE 0 END AS laborrela_fee -- 劳动关系成本 ,CASE WHEN dimaccountcode in('WY040105','WY040114','WY040106','WY040113') -- 工会经费,残疾人保障金,职工教育经费,汽车费 THEN diff_amount ELSE 0 END AS other_fee -- 其他费用 ,diff_amount AS total_fee -- 当期小计 ,'差额' AS fee_type -- 费用类型 from dw.dwd_cost_detail_data_d where cost_code = 'AC' -- 人力成本 )A GROUP BY A.yearname ,A.monthname ,A.organ_code ,A.organ_name ,A.dimsubjectcode ,A.dimsubjectname ,A.fee_type UNION ALL select yearname -- 年 ,monthname -- 月 ,organ_code -- 片区ID ,organ_name -- 片区名称 ,dimsubjectcode -- 组织机构编码 ,dimsubjectname -- 组织机构名称 ,CASE WHEN SUM(CASE WHEN dimaccountcode = 'WY040101' THEN target_fee ELSE 0 END) = 0 THEN '0%' ELSE CONCAT(ROUND((SUM(CASE WHEN dimaccountcode = 'WY040101' THEN actual_fee ELSE 0 END) / SUM(CASE WHEN dimaccountcode = 'WY040101' THEN target_fee ELSE 0 END))*100,2),'%') END AS salary_fee -- 工资 ,CASE WHEN SUM(CASE WHEN dimaccountcode = 'WY040102' THEN target_fee ELSE 0 END) = 0 THEN '0%' ELSE CONCAT(ROUND((SUM(CASE WHEN dimaccountcode = 'WY040102' THEN actual_fee ELSE 0 END) / SUM(CASE WHEN dimaccountcode = 'WY040102' THEN target_fee ELSE 0 END))*100,2),'%') END AS year_performance_fee-- 季度/年终绩效 ,CASE WHEN SUM(CASE WHEN dimaccountcode = 'WY040104' THEN target_fee ELSE 0 END) = 0 THEN '0%' ELSE CONCAT(ROUND((SUM(CASE WHEN dimaccountcode = 'WY040104' THEN actual_fee ELSE 0 END) / SUM(CASE WHEN dimaccountcode = 'WY040104' THEN target_fee ELSE 0 END))*100,2),'%') END AS social_insur_fee -- 社会保险 ,CASE WHEN SUM(CASE WHEN dimaccountcode = 'WY040109' THEN target_fee ELSE 0 END) = 0 THEN '0%' ELSE CONCAT(ROUND((SUM(CASE WHEN dimaccountcode = 'WY040109' THEN actual_fee ELSE 0 END) / SUM(CASE WHEN dimaccountcode = 'WY040109' THEN target_fee ELSE 0 END))*100,2),'%') END AS accumu_fund_fee -- 公积金 ,CASE WHEN SUM(CASE WHEN dimaccountcode = 'WY040112' THEN target_fee ELSE 0 END) = 0 THEN '0%' ELSE CONCAT(ROUND((SUM(CASE WHEN dimaccountcode = 'WY040112' THEN actual_fee ELSE 0 END) / SUM(CASE WHEN dimaccountcode = 'WY040112' THEN target_fee ELSE 0 END))*100,2),'%') END AS liab_insur_fee -- 雇主责任险 ,CASE WHEN SUM(CASE WHEN dimaccountcode = 'WY040111' THEN target_fee ELSE 0 END) = 0 THEN '0%' ELSE CONCAT(ROUND((SUM(CASE WHEN dimaccountcode = 'WY040111' THEN actual_fee ELSE 0 END) / SUM(CASE WHEN dimaccountcode = 'WY040111' THEN target_fee ELSE 0 END))*100,2),'%') END AS smock_fee -- 工作服 ,CASE WHEN SUM(CASE WHEN dimaccountcode = 'WY040107' THEN target_fee ELSE 0 END) = 0 THEN '0%' ELSE CONCAT(ROUND((SUM(CASE WHEN dimaccountcode = 'WY040107' THEN actual_fee ELSE 0 END) / SUM(CASE WHEN dimaccountcode = 'WY040107' THEN target_fee ELSE 0 END))*100,2),'%') END AS train_fee -- 培训 ,CASE WHEN SUM(CASE WHEN dimaccountcode = 'WY040110' THEN target_fee ELSE 0 END) = 0 THEN '0%' ELSE CONCAT(ROUND((SUM(CASE WHEN dimaccountcode = 'WY040110' THEN actual_fee ELSE 0 END) / SUM(CASE WHEN dimaccountcode = 'WY040110' THEN target_fee ELSE 0 END))*100,2),'%') END AS recr_fee -- 招聘 ,CASE WHEN SUM(CASE WHEN dimaccountcode = 'WY040103' THEN target_fee ELSE 0 END) = 0 THEN '0%' ELSE CONCAT(ROUND((SUM(CASE WHEN dimaccountcode = 'WY040103' THEN actual_fee ELSE 0 END) / SUM(CASE WHEN dimaccountcode = 'WY040103' THEN target_fee ELSE 0 END))*100,2),'%') END AS emp_bene_fee -- 员工福利 ,CASE WHEN SUM(CASE WHEN dimaccountcode = 'WY040108' THEN target_fee ELSE 0 END) = 0 THEN '0%' ELSE CONCAT(ROUND((SUM(CASE WHEN dimaccountcode = 'WY040108' THEN actual_fee ELSE 0 END) / SUM(CASE WHEN dimaccountcode = 'WY040108' THEN target_fee ELSE 0 END))*100,2),'%') END AS laborrela_fee -- 劳动关系成本 ,CASE WHEN SUM(CASE WHEN dimaccountcode in('WY040105','WY040114','WY040106','WY040113') THEN target_fee ELSE 0 END) = 0 THEN '0%' ELSE CONCAT(ROUND((SUM(CASE WHEN dimaccountcode in('WY040105','WY040114','WY040106','WY040113') THEN actual_fee ELSE 0 END) / SUM(CASE WHEN dimaccountcode in('WY040105','WY040114','WY040106','WY040113') THEN target_fee ELSE 0 END))*100,2),'%') END AS other_fee -- 其他费用 ,CASE WHEN SUM(target_fee) = 0 THEN '0%' ELSE CONCAT(ROUND((SUM(actual_fee) / SUM(target_fee))*100,2),'%') END AS total_fee -- 当期小计 ,'执行率' AS fee_type -- 费用类型 from dw.dwd_cost_detail_data_d where cost_code = 'AC' -- 人力成本 GROUP BY yearname -- 年 ,monthname -- 月 ,organ_code -- 片区ID ,organ_name -- 片区名称 ,dimsubjectcode -- 组织机构编码 ,dimsubjectname -- 组织机构名称 ;