leading-project/dw/ods/ods_cost_budget_data_d.sql
2024-11-27 11:07:58 +08:00

292 lines
15 KiB
SQL

-- RENAME TABLE ods_cost_budgetdata_d TO ods_cost_budget_data_d;
CREATE TABLE IF NOT EXISTS dw.ods_cost_budget_data_d(
dimaccountcode VARCHAR(255) COMMENT '预算科目编码'
,dimaccountname VARCHAR(255) COMMENT '预算科目名称'
,dimsubjectcode VARCHAR(255) COMMENT '组织机构编码'
,dimsubjectname VARCHAR(255) COMMENT '组织机构名称'
,yearname VARCHAR(100) COMMENT ''
,totalcode VARCHAR(255) COMMENT '组织机构层级编码'
,janbuget VARCHAR(255) COMMENT '1月预算金额'
,janocc VARCHAR(255) COMMENT '1月已占用金额'
,janreal VARCHAR(255) COMMENT '1月已使用金额'
,janavailable VARCHAR(255) COMMENT '1月剩余可用金额'
,janbugetrate VARCHAR(100) COMMENT '1月预算执行率'
,febbudget VARCHAR(255) COMMENT '2月预算金额'
,febocc VARCHAR(255) COMMENT '2月已占用金额'
,febreal VARCHAR(255) COMMENT '2月已使用金额'
,febavailable VARCHAR(255) COMMENT '2月剩余可用金额'
,febbudgetrate VARCHAR(100) COMMENT '2月预算执行率'
,marbudget VARCHAR(255) COMMENT '3月预算金额'
,marocc VARCHAR(255) COMMENT '3月已占用金额'
,marreal VARCHAR(255) COMMENT '3月已使用金额'
,maravailable VARCHAR(255) COMMENT '3月剩余可用金额'
,marbudgetrate VARCHAR(100) COMMENT '3月预算执行率'
,aprilbudget VARCHAR(255) COMMENT '4月预算金额'
,aprilocc VARCHAR(255) COMMENT '4月已占用金额'
,aprilreal VARCHAR(255) COMMENT '4月已使用金额'
,apravailable VARCHAR(255) COMMENT '4月剩余可用金额'
,aprilbudgetrate VARCHAR(100) COMMENT '4月预算执行率'
,maybudget VARCHAR(255) COMMENT '5月预算金额'
,mayocc VARCHAR(255) COMMENT '5月已占用金额'
,mayreal VARCHAR(255) COMMENT '5月已使用金额'
,mayavailable VARCHAR(255) COMMENT '5月剩余可用金额'
,maybudgetrate VARCHAR(100) COMMENT '5月预算执行率'
,junebudget VARCHAR(255) COMMENT '6月预算金额'
,juneocc VARCHAR(255) COMMENT '6月已占用金额'
,junereal VARCHAR(255) COMMENT '6月已使用金额'
,juneavailable VARCHAR(255) COMMENT '6月剩余可用金额'
,junebudgetrate VARCHAR(100) COMMENT '6月预算执行率'
,julybudget VARCHAR(255) COMMENT '7月预算金额'
,julyocc VARCHAR(255) COMMENT '7月已占用金额'
,julyreal VARCHAR(255) COMMENT '7月已使用金额'
,julyavailable VARCHAR(255) COMMENT '7月剩余可用金额'
,julybudgetrate VARCHAR(100) COMMENT '7月预算执行率'
,augbudget VARCHAR(255) COMMENT '8月预算金额'
,augocc VARCHAR(255) COMMENT '8月已占用金额'
,augreal VARCHAR(255) COMMENT '8月已使用金额'
,augavailable VARCHAR(255) COMMENT '8月剩余可用金额'
,augbudgetrate VARCHAR(100) COMMENT '8月预算执行率'
,sepbudget VARCHAR(255) COMMENT '9月预算金额'
,sepocc VARCHAR(255) COMMENT '9月已占用金额'
,sepreal VARCHAR(255) COMMENT '9月已使用金额'
,sepavailable VARCHAR(255) COMMENT '9月剩余可用金额'
,sepbudgetrate VARCHAR(100) COMMENT '9月预算执行率'
,octbudget VARCHAR(255) COMMENT '10月预算金额'
,octocc VARCHAR(255) COMMENT '10月已占用金额'
,octreal VARCHAR(255) COMMENT '10月已使用金额'
, octavailable VARCHAR(255) COMMENT '10月剩余可用金额'
,octbudgetrate VARCHAR(100) COMMENT '10月预算执行率'
,novbudget VARCHAR(255) COMMENT '11月预算金额'
,novocc VARCHAR(255) COMMENT '11月已占用金额'
,novreal VARCHAR(255) COMMENT '11月已使用金额'
,novavailable VARCHAR(255) COMMENT '11月剩余可用金额'
,novbudgetrate VARCHAR(100) COMMENT '11月预算执行率'
,decbudget VARCHAR(255) COMMENT '12月预算金额'
,decocc VARCHAR(255) COMMENT '12月已占用金额'
,decreal VARCHAR(255) COMMENT '12月已使用金额'
,decavailable VARCHAR(255) COMMENT '12月剩余可用金额'
,decbudgetrate VARCHAR(100) COMMENT '12月预算执行率'
)COMMENT = '费控预算数据'
;
select
dimaccountcode as dimaccountcode --预算科目编码
,dimaccountname as dimaccountname --预算科目名称
,DimSubjectcode as DimSubjectcode --组织机构编码
,DimSubjectname as DimSubjectname --组织机构名称
,yearname as yearname --年
,totalcode as totalcode --组织机构层级编码
,z.Janbuget as Janbuget --1月预算金额
,z.Janocc as Janocc --1月已占用金额
,z.Janreal as Janreal --1月已使用金额
,z.Janbuget-z.Janocc-z.Janreal as Janavailable --1月剩余可用金额
,case when z.Janbuget<> 0 then (round(((z.Janocc+z.Janreal)/z.Janbuget)*100,2) ||'%') else '0%' end
as Janbugetrate --1月预算执行率
,z.Febbudget as Febbudget --2月预算金额
,z.Febocc as Febocc --2月已占用金额
,z.Febreal as Febreal --2月已使用金额
,z.Febbudget-z.Febocc-z.Febreal as Febavailable --2月剩余可用金额
,case when z.Febbudget<> 0 then (round(((z.Febocc+z.Febreal)/z.Febbudget)*100,2) ||'%') else '0%' end
as Febbudgetrate --2月预算执行率
,z.Marbudget as Marbudget --3月预算金额
,z.Marocc as Marocc --3月已占用金额
,z.Marreal as Marreal --3月已使用金额
,z.Marbudget-z.Marocc-z.Marreal as Maravailable -- 3月剩余可用金额
,case when z.Marbudget<> 0 then (round(((z.Marocc+z.Marreal)/z.Marbudget)*100,2) ||'%') else '0%' end
as Marbudgetrate --3月预算执行率
,z.Aprilbudget as Aprilbudget --4月预算金额
,z.Aprilocc as Aprilocc --4月已占用金额
,z.Aprilreal as Aprilreal --4月已使用金额
,z.Aprilbudget-z.Aprilocc-z.Aprilreal as Apravailable --4月剩余可用金额
,case when z.Aprilbudget<> 0 then (round(((z.Aprilocc+z.Aprilreal)/z.Aprilbudget)*100,2) ||'%') else '0%' end
as Aprilbudgetrate --4月预算执行率
,z.Maybudget as Maybudget --5月预算金额
,z.Mayocc as Mayocc --5月已占用金额
,z.Mayreal as Mayreal --5月已使用金额
,z.Maybudget-z.Mayocc-z.Mayreal as Mayavailable --5月剩余可用金额
,case when z.Maybudget<> 0 then (round(((z.Mayocc+z.Mayreal)/z.Maybudget)*100,2) ||'%') else '0%' end
as Maybudgetrate --5月预算执行率
,z.Junebudget as Junebudget --6月预算金额
,z.Juneocc as Juneocc --6月已占用金额
,z.Junereal as Junereal --6月已使用金额
,z.Junebudget-z.Juneocc-z.Junereal as Juneavailable --6月剩余可用金额
,case when z.Junebudget<> 0 then (round(((z.Juneocc+z.Junereal)/z.Junebudget)*100,2) ||'%') else '0%' end
as Junebudgetrate --6月预算执行率
,z.Julybudget as Julybudget --7月预算金额
,z.Julyocc as Julyocc --7月已占用金额
,z.Julyreal as Julyreal --7月已使用金额
,z.Julybudget-z.Julyocc-z.Julyreal as Julyavailable --7月剩余可用金额
,case when z.Julybudget<> 0 then (round(((z.Julyocc+z.Julyreal)/z.Julybudget)*100,2) ||'%') else '0%' end
as Julybudgetrate --7月预算执行率
,z.Augbudget as Augbudget --8月预算金额
,z.Augocc as Augocc --8月已占用金额
,z.Augreal as Augreal --8月已使用金额
,z.Augbudget-z.Augocc-z.Augreal as Augavailable -- 8月剩余可用金额
,case when z.Augbudget<> 0 then (round(((z.Augocc+z.Augreal)/z.Augbudget)*100,2) ||'%') else '0%' end
as Augbudgetrate --8月预算执行率
,z.Sepbudget as Sepbudget --9月预算金额
,z.Sepocc as Sepocc --9月已占用金额
,z.Sepreal as Sepreal --9月已使用金额
,z.Sepbudget-z.Sepocc-z.Sepreal as Sepavailable --9月剩余可用金额
,case when z.Sepbudget<> 0 then (round(((z.Sepocc+z.Sepreal)/z.Sepbudget)*100,2) ||'%') else '0%' end
as Sepbudgetrate --9月预算执行率
,z.Octbudget as Octbudget --10月预算金额
,z.Octocc as Octocc --10月已占用金额
,z.Octreal as Octreal --10月已使用金额
,z.Octbudget-z.Octocc-z.Octreal as Octavailable --10月剩余可用金额
,case when z.Octbudget<> 0 then (round(((z.Octocc+z.Octreal)/z.Octbudget)*100,2) ||'%') else '0%' end
as Octbudgetrate --10月预算执行率
,z.Novbudget as Novbudget --11月预算金额
,z.Novocc as Novocc --11月已占用金额
,z.Novreal as Novreal --11月已使用金额
,z.Novbudget-z.Novocc-z.Novreal as Novavailable --11月剩余可用金额
,case when z.Novbudget<> 0 then (round(((z.Novocc+z.Novreal)/z.Novbudget)*100,2) ||'%') else '0%' end
as Novbudgetrate --11月预算执行率
,z.Decbudget as Decbudget --12月预算金额
,z.DecOcc as DecOcc --12月已占用金额
,z.Decreal as Decreal --12月已使用金额
,z.Decbudget-z.DecOcc-z.Decreal as Decavailable --12月剩余可用金额
,case when z.Decbudget<> 0 then (round(((z.DecOcc+z.Decreal)/z.Decbudget)*100,2) ||'%') else '0%' end
as Decbudgetrate --12月预算执行率
from
(
select
dimaccountcode
,dimaccountname
,DimSubjectcode
,DimSubjectname
,yearname
,totalcode
,sum(Janbuget) as Janbuget
,sum(Janocc) as Janocc
,sum(Janreal) as Janreal,
sum(Febbudget) as Febbudget,
sum(Febreal) as Febreal,
sum(Febocc) as Febocc,
sum(Marbudget) as Marbudget,
sum(Marocc) as Marocc,
sum(Marreal) as Marreal,
sum(Aprilbudget) as Aprilbudget,
sum(Aprilocc) as Aprilocc,
sum(Aprilreal) as Aprilreal,
sum(Maybudget) as Maybudget,
sum(Mayocc) as Mayocc,
sum(Mayreal) as Mayreal,
sum(Junebudget) as Junebudget,
sum(Juneocc) as Juneocc,
sum(Junereal) as Junereal,
sum(Julybudget) as Julybudget,
sum(Julyocc) as Julyocc,
sum(Julyreal) as Julyreal,
sum(Augbudget) as Augbudget,
sum(Augocc) as Augocc,
sum(Augreal) as Augreal,
sum(Sepbudget) as Sepbudget,
sum(Sepocc) as Sepocc,
sum(Sepreal) as Sepreal,
sum(Octbudget) as Octbudget,
sum(Octocc) as Octocc,
sum(Octreal) as Octreal,
sum(Novbudget) as Novbudget,
sum(Novocc) as Novocc,
sum(Novreal) as Novreal,
sum(Decbudget) as Decbudget,
sum(DecOcc) as DecOcc,
sum(Decreal) as Decreal
from
(
select
str.DimSubjectid
,o.objectcode as dimaccountcode
,o.objectname as dimaccountname
,o1.objectcode as DimSubjectcode
,o1.objectname as DimSubjectname
,yea.objectName as yearname
,o1.totalcode
,( case when b.datatype =0 then b.M1 end) Janbuget,
(case when b.datatype =1 then b.M1 end) Janreal ,
(case when b.datatype =2 then b.M1 end) Janocc ,
(case when b.datatype =0 then b.M2 end) Febbudget,
(case when b.datatype =1 then b.M2 end) Febreal,
(case when b.datatype =2 then b.M2 end) Febocc,
(case when b.datatype =0 then b.M3 end) Marbudget,
(case when b.datatype =1 then b.M3 end) Marreal,
(case when b.datatype =2 then b.M3 end) Marocc,
(case when b.datatype =0 then b.M4 end) Aprilbudget,
(case when b.datatype =1 then b.M4 end) Aprilreal,
(case when b.datatype =2 then b.M4 end) Aprilocc,
(case when b.datatype =0 then b.M5 end) Maybudget,
(case when b.datatype =1 then b.M5 end) Mayreal,
(case when b.datatype =2 then b.M5 end) Mayocc,
(case when b.datatype =0 then b.M6 end) Junebudget,
(case when b.datatype =1 then b.M6 end) Junereal,
(case when b.datatype =2 then b.M6 end) Juneocc,
(case when b.datatype =0 then b.M7 end) Julybudget,
(case when b.datatype =1 then b.M7 end) Julyreal,
(case when b.datatype =2 then b.M7 end) Julyocc,
(case when b.datatype =0 then b.M8 end)Augbudget,
(case when b.datatype =1 then b.M8 end) Augreal,
(case when b.datatype =2 then b.M8 end) Augocc,
(case when b.datatype =0 then b.M9 end)Sepbudget,
(case when b.datatype =1 then b.M9 end) Sepreal,
(case when b.datatype =2 then b.M9 end) Sepocc,
(case when b.datatype =0 then b.M10 end)Octbudget,
(case when b.datatype =1 then b.M10 end) Octreal,
(case when b.datatype =2 then b.M10 end) Octocc,
(case when b.datatype =0 then b.M11 end)Novbudget,
(case when b.datatype =1 then b.M11 end) Novreal,
(case when b.datatype =2 then b.M11 end) Novocc,
(case when b.datatype =0 then b.M12 end)Decbudget,
(case when b.datatype =1 then b.M12 end) Decreal,
(case when b.datatype =2 then b.M12 end) DecOcc
from e7fssc_ld.t_cc_budgetdata b
left join e7fssc_ld.t_cc_structure str on str.structureid = b.structureid
left join e7fssc_ld.t_cc_object o on o.objectid=str.dimaccountid
left join e7fssc_ld.t_cc_object o1 on o1.objectid=str.dimsubjectid
left join e7fssc_ld.t_cc_object yea on yea.objectId = b.yearId
where 1=1
)
group by
dimaccountcode
,dimaccountname
,DimSubjectcode
,DimSubjectname
,yearname
,totalcode
)z
-- where条件需要根据实际业务需求去添加
where 1 = 1
-- AND z.yearname='2024'
-- and z.dimsubjectcode='010201011105'
and totalcode like '0001,1001,2002,3000%' --注意该条件,本次项目只需要该条件即可
-- order by totalcode