leading-project/dw/dwd/dwd_cost_detail_data_d.sql

201 lines
11 KiB
SQL
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

-- -----------------------------------
-- 费控明细表建表
-- -----------------------------------
DROP TABLE IF EXISTS dw.dwd_cost_detail_data_d;
CREATE TABLE IF NOT EXISTS dw.dwd_cost_detail_data_d (
yearname VARCHAR(50) COMMENT ''
,monthname VARCHAR(50) COMMENT ''
,organ_code VARCHAR(255) COMMENT '片区ID'
,organ_name VARCHAR(255) COMMENT '片区名称'
,cost_code VARCHAR(50) COMMENT '成本类型编码: LC:行政成本 AC:人力成本'
,cost_name VARCHAR(50) COMMENT '成本类型名称'
,dimsubjectcode VARCHAR(255) COMMENT '组织机构编码'
,dimsubjectname VARCHAR(255) COMMENT '组织机构名称'
,totalcode VARCHAR(255) COMMENT '组织机构层级编码'
,dimaccountcode VARCHAR(255) COMMENT '预算科目编码'
,dimaccountname VARCHAR(255) COMMENT '预算科目名称'
,buget VARCHAR(255) COMMENT '预算金额'
,occ VARCHAR(255) COMMENT '已占用金额'
,realfee VARCHAR(255) COMMENT '已使用金额'
,available VARCHAR(255) COMMENT '剩余可用金额'
,budgetfee_rate VARCHAR(50) COMMENT '预算执行率'
,originalcurrency VARCHAR(255) COMMENT '调整金额'
,target_fee VARCHAR(255) COMMENT '目标值'
,actual_fee VARCHAR(255) COMMENT '实际值'
,diff_amount VARCHAR(255) COMMENT '差额'
,implementation_rate VARCHAR(50) COMMENT '执行率'
)COMMENT = '费控明细表';
-- ****************************************
-- 创建人员: 杨坤安
-- 创建日期: 2024-07-19
-- 功 能: 费控明细表
-- ****************************************
-- ----------------------------------------------------------------------------------------------
-- 【指标计算】
-- 预算金额 - 调整金额 = 预算初期金额
-- 查询预算sql的预算金额年月需要和调整金额sql中的年月一致-调整金额sql的调整金额=预算初期金额
-- 目标值 = 预算金额 - 调整金额
-- 实际值 = 已使用金额
-- 差额 = 目标值 - 实际值
-- 执行率 = 实际值 / 目标值
-- ----------------------------------------------------------------------------------------------
truncate dw.dwd_cost_detail_data_d;
INSERT into dw.dwd_cost_detail_data_d
SELECT
T1.yearname AS yearname -- 年
,T1.monthname AS monthname -- 月
,T2.organ_code AS organ_code -- 片区ID
,T2.organ_name AS organ_name -- 片区名称
,T1.cost_code AS cost_code -- 成本类型编码: LC:行政成本 AC:人力成本
,T1.cost_name AS cost_name -- 成本类型名称
,T1.dimsubjectcode AS dimsubjectcode -- 组织机构编码
,T1.dimsubjectname AS dimsubjectname -- 组织机构名称
,T1.totalcode AS totalcode -- 组织机构层级编码
,T1.dimaccountcode AS dimaccountcode -- 预算科目编码
,T1.dimaccountname AS dimaccountname -- 预算科目名称
,T1.buget AS buget -- 预算金额
,T1.occ AS occ -- 已占用金额
,T1.realfee AS realfee -- 已使用金额
,T1.available AS available -- 剩余可用金额
,T1.budgetfee_rate AS budgetfee_rate -- 预算执行率
,T1.originalcurrency AS originalcurrency -- 调整金额
,T1.target_fee AS target_fee -- 目标值
,T1.actual_fee AS actual_fee -- 实际值
,ROUND((T1.target_fee - T1.actual_fee),2) AS diff_amount -- 差额
,case when T1.target_fee = 0 then '0%' else concat(ROUND((T1.actual_fee / T1.target_fee)*100,2),'%') end AS implementation_rate -- 执行率
FROM
(
SELECT
A.yearname AS yearname -- 年
,A.monthname AS monthname -- 月
,'LC' AS cost_code -- 成本类型编码: LC:行政成本 AC:人力成本
,'行政成本' AS cost_name -- 成本类型名称
,A.dimsubjectcode AS dimsubjectcode -- 组织机构编码
,A.dimsubjectname AS dimsubjectname -- 组织机构名称
,A.totalcode AS totalcode -- 组织机构层级编码
,A.dimaccountcode AS dimaccountcode -- 预算科目编码
,A.dimaccountname AS dimaccountname -- 预算科目名称
,A.buget AS buget -- 预算金额
,A.occ AS occ -- 已占用金额
,A.realfee AS realfee -- 已使用金额
,A.available AS available -- 剩余可用金额
,A.budgetfee_rate AS budgetfee_rate -- 预算执行率
,COALESCE(B.originalcurrency,0) AS originalcurrency -- 调整金额
,ROUND((A.buget - COALESCE(B.originalcurrency,0)),2) AS target_fee -- 目标值
,A.realfee AS actual_fee -- 实际值
-- ,'' AS diff_amount -- 差额
-- ,'' AS implementation_rate -- 执行率
FROM
(
SELECT
dimaccountcode -- 预算科目编码
,dimaccountname -- 预算科目名称
,dimsubjectcode -- 组织机构编码
,dimsubjectname -- 组织机构名称
,yearname -- 年
,totalcode -- 组织机构层级编码
,monthname -- 月
,buget -- 预算金额
,occ -- 已占用金额
,realfee -- 已使用金额
,available -- 剩余可用金额
,budgetfee_rate -- 预算执行率
FROM dw.dwd_cost_budget_data_d -- 预算金额明细表
WHERE dimaccountcode IN('WY0402','WY040201','WY040202','WY040203','WY040204','WY040205','WY040206','WY040207','WY040208','WY040209','WY040210','WY040211','WY040212','WY040213','WY040214','WY040215','WY040216')
)A
LEFT JOIN
(
SELECT
year -- 年
,month -- 月
,dimsubjectcode -- 调整组织机构编码
,dimaccountcode -- 调整预算科目编码
,originalcurrency -- 调整金额
FROM dw.dwd_cost_adjust_data_d -- 调整金额明细表
WHERE dimaccountcode IN('WY0402','WY040201','WY040202','WY040203','WY040204','WY040205','WY040206','WY040207','WY040208','WY040209','WY040210','WY040211','WY040212','WY040213','WY040214','WY040215','WY040216')
)B
ON A.dimaccountcode = B.dimaccountcode
AND A.dimsubjectcode = B.dimsubjectcode
AND A.yearname = B.year
AND A.monthname = B.month
UNION ALL
SELECT
A.yearname AS yearname -- 年
,A.monthname AS monthname -- 月
,'AC' AS cost_code -- 成本类型编码: LC:行政成本 AC:人力成本
,'人力成本' AS cost_name -- 成本类型名称
,A.dimsubjectcode AS dimsubjectcode -- 组织机构编码
,A.dimsubjectname AS dimsubjectname -- 组织机构名称
,A.totalcode AS totalcode -- 组织机构层级编码
,A.dimaccountcode AS dimaccountcode -- 预算科目编码
,A.dimaccountname AS dimaccountname -- 预算科目名称
,A.buget AS buget -- 预算金额
,A.occ AS occ -- 已占用金额
,A.realfee AS realfee -- 已使用金额
,A.available AS available -- 剩余可用金额
,A.budgetfee_rate AS budgetfee_rate -- 预算执行率
,COALESCE(B.originalcurrency,0) AS originalcurrency -- 调整金额
,ROUND((A.buget - COALESCE(B.originalcurrency,0)),2) AS target_fee -- 目标值
,A.realfee AS actual_fee -- 实际值
-- ,'' AS diff_amount -- 差额
-- ,'' AS implementation_rate -- 执行率
FROM
(
SELECT
dimaccountcode -- 预算科目编码
,dimaccountname -- 预算科目名称
,dimsubjectcode -- 组织机构编码
,dimsubjectname -- 组织机构名称
,yearname -- 年
,totalcode -- 组织机构层级编码
,monthname -- 月
,buget -- 预算金额
,occ -- 已占用金额
,realfee -- 已使用金额
,available -- 剩余可用金额
,budgetfee_rate -- 预算执行率
FROM dw.dwd_cost_budget_data_d -- 预算金额明细表
WHERE dimaccountcode IN('WY0401','WY040101','WY040102','WY040103','WY040104','WY040105','WY040106','WY040107','WY040108','WY040109','WY040110','WY040111','WY040112','WY040113','WY040114')
)A
LEFT JOIN
(
SELECT
year -- 年
,month -- 月
,dimsubjectcode -- 调整组织机构编码
,dimaccountcode -- 调整预算科目编码
,originalcurrency -- 调整金额
FROM dw.dwd_cost_adjust_data_d -- 调整金额明细表
WHERE dimaccountcode IN('WY0401','WY040101','WY040102','WY040103','WY040104','WY040105','WY040106','WY040107','WY040108','WY040109','WY040110','WY040111','WY040112','WY040113','WY040114')
)B
ON A.dimaccountcode = B.dimaccountcode
AND A.dimsubjectcode = B.dimsubjectcode
AND A.yearname = B.year
AND A.monthname = B.month
)T1
LEFT JOIN
(
SELECT
organ_code -- erp片区id
,organ_name -- erp片区名称
,cost_comm_id -- 费控项目id
FROM dw.dim_organ_mapping -- 片区项目映射维度表
where cost_comm_id is not null
GROUP BY
organ_code -- erp片区id
,organ_name -- erp片区名称
,cost_comm_id -- 费控项目id
)T2
ON T1.dimsubjectcode = T2.cost_comm_id
;