WITH corp AS ( SELECT corp_code -- 公司编码 ,corp_name -- 公司名称 FROM dwr.dim_corp a WHERE corp_type = '实体' AND (parent_corp_code LIKE '02%' OR corp_code = '0301') AND exists ( select 1 from dm.dm_bi_user_permisson where bi_user = '${fine_username}' and per_model IN ('all','sal') and ( is_all = 1 OR per_code = a.corp_code ) ) ${IF(LEN(sCorp)!=0," AND corp_code IN ('"+ sCorp +"')", "")} ), base_info_curr AS ( SELECT A.subject_code AS subject_code -- 科目编码 ,SUM(A.debit_amt) AS debit_amt_y -- 借方金额_当年累计 ,SUM(IF(A.acnt_mon = '${FORMAT(sStart_mon,"MM")}',A.debit_amt,0)) AS debit_amt_m -- 借方金额_当月累计 FROM dwr.fact_fim_subject_balance A-- 科目余额 JOIN corp B ON A.corp_code = B.corp_code WHERE A.subject_code like '6604%' AND A.acnt_year = '${YEAR(sStart_mon)}' AND A.acnt_mon <= '${FORMAT(sStart_mon,"MM")}' GROUP BY A.subject_code ), base_info_last AS ( SELECT A.subject_code AS subject_code -- 科目编码 ,SUM(A.debit_amt) AS debit_amt_y -- 借方金额_当年累计 ,SUM(IF(A.acnt_mon = '${FORMAT(sStart_mon,"MM")}',A.debit_amt,0)) AS debit_amt_m -- 借方金额_当月累计 FROM dwr.fact_fim_subject_balance A-- 科目余额 JOIN corp B ON A.corp_code = B.corp_code WHERE A.subject_code like '6604%' AND A.acnt_year = '${YEAR(sStart_mon) - 1}' AND A.acnt_mon <= '${FORMAT(sStart_mon,"MM")}' GROUP BY A.subject_code ), subject_result AS ( -- 本期统计 SELECT '材料费' AS subject_name -- 科目名称 ,'660401' AS subject_code -- 科目编码 ,SUM(debit_amt_m) AS debit_amt_m -- 借方金额_当月累计 ,SUM(debit_amt_y) AS debit_amt_y -- 借方金额_当年累计 ,0 AS debit_amt_last_m -- 借方金额_上年同期 ,0 AS debit_amt_last_y -- 借方金额_上年累计 FROM base_info_curr WHERE subject_code like '660401%' UNION ALL SELECT '职工薪酬' AS subject_name -- 科目名称 ,'660403' AS subject_code -- 科目编码 ,SUM(debit_amt_m) AS debit_amt_m -- 借方金额_当月累计 ,SUM(debit_amt_y) AS debit_amt_y -- 借方金额_当年累计 ,0 AS debit_amt_last_m -- 借方金额_上年同期 ,0 AS debit_amt_last_y -- 借方金额_上年累计 FROM base_info_curr WHERE subject_code like '660403%' UNION ALL SELECT '差旅费' AS subject_name -- 科目名称 ,'660409' AS subject_code -- 科目编码 ,SUM(debit_amt_m) AS debit_amt_m -- 借方金额_当月累计 ,SUM(debit_amt_y) AS debit_amt_y -- 借方金额_当年累计 ,0 AS debit_amt_last_m -- 借方金额_上年同期 ,0 AS debit_amt_last_y -- 借方金额_上年累计 FROM base_info_curr WHERE subject_code like '660409%' UNION ALL SELECT '加工费' AS subject_name -- 科目名称 ,'660408' AS subject_code -- 科目编码 ,SUM(debit_amt_m) AS debit_amt_m -- 借方金额_当月累计 ,SUM(debit_amt_y) AS debit_amt_y -- 借方金额_当年累计 ,0 AS debit_amt_last_m -- 借方金额_上年同期 ,0 AS debit_amt_last_y -- 借方金额_上年累计 FROM base_info_curr WHERE subject_code like '660408%' UNION ALL SELECT '技术服务费' AS subject_name -- 科目名称 ,'660402' AS subject_code -- 科目编码 ,SUM(debit_amt_m) AS debit_amt_m -- 借方金额_当月累计 ,SUM(debit_amt_y) AS debit_amt_y -- 借方金额_当年累计 ,0 AS debit_amt_last_m -- 借方金额_上年同期 ,0 AS debit_amt_last_y -- 借方金额_上年累计 FROM base_info_curr WHERE subject_code like '660402%' UNION ALL SELECT '其他' AS subject_name -- 科目名称 ,'0000' AS subject_code -- 科目编码 ,SUM(debit_amt_m) AS debit_amt_m -- 借方金额_当月累计 ,SUM(debit_amt_y) AS debit_amt_y -- 借方金额_当年累计 ,0 AS debit_amt_last_m -- 借方金额_上年同期 ,0 AS debit_amt_last_y -- 借方金额_上年累计 FROM base_info_curr WHERE (subject_code NOT like '660401%' AND subject_code NOT like '660403%' AND subject_code NOT like '660409%' AND subject_code NOT like '660408%' AND subject_code NOT like '660402%') UNION ALL -- 上期统计 SELECT '材料费' AS subject_name -- 科目名称 ,'660401' AS subject_code -- 科目编码 ,0 AS debit_amt_m -- 借方金额_当月累计 ,0 AS debit_amt_y -- 借方金额_当年累计 ,SUM(debit_amt_m) AS debit_amt_last_m -- 借方金额_上年同期 ,SUM(debit_amt_y) AS debit_amt_last_y -- 借方金额_上年累计 FROM base_info_last WHERE subject_code like '660401%' UNION ALL SELECT '职工薪酬' AS subject_name -- 科目名称 ,'660403' AS subject_code -- 科目编码 ,0 AS debit_amt_m -- 借方金额_当月累计 ,0 AS debit_amt_y -- 借方金额_当年累计 ,SUM(debit_amt_m) AS debit_amt_last_m -- 借方金额_上年同期 ,SUM(debit_amt_y) AS debit_amt_last_y -- 借方金额_上年累计 FROM base_info_last WHERE subject_code like '660403%' UNION ALL SELECT '差旅费' AS subject_name -- 科目名称 ,'660409' AS subject_code -- 科目编码 ,0 AS debit_amt_m -- 借方金额_当月累计 ,0 AS debit_amt_y -- 借方金额_当年累计 ,SUM(debit_amt_m) AS debit_amt_last_m -- 借方金额_上年同期 ,SUM(debit_amt_y) AS debit_amt_last_y -- 借方金额_上年累计 FROM base_info_last WHERE subject_code like '660409%' UNION ALL SELECT '加工费' AS subject_name -- 科目名称 ,'660408' AS subject_code -- 科目编码 ,0 AS debit_amt_m -- 借方金额_当月累计 ,0 AS debit_amt_y -- 借方金额_当年累计 ,SUM(debit_amt_m) AS debit_amt_last_m -- 借方金额_上年同期 ,SUM(debit_amt_y) AS debit_amt_last_y -- 借方金额_上年累计 FROM base_info_last WHERE subject_code like '660408%' UNION ALL SELECT '技术服务费' AS subject_name -- 科目名称 ,'660402' AS subject_code -- 科目编码 ,0 AS debit_amt_m -- 借方金额_当月累计 ,0 AS debit_amt_y -- 借方金额_当年累计 ,SUM(debit_amt_m) AS debit_amt_last_m -- 借方金额_上年同期 ,SUM(debit_amt_y) AS debit_amt_last_y -- 借方金额_上年累计 FROM base_info_last WHERE subject_code like '660402%' UNION ALL SELECT '其他' AS subject_name -- 科目名称 ,'0000' AS subject_code -- 科目编码 ,0 AS debit_amt_m -- 借方金额_当月累计 ,0 AS debit_amt_y -- 借方金额_当年累计 ,SUM(debit_amt_m) AS debit_amt_last_m -- 借方金额_上年同期 ,SUM(debit_amt_y) AS debit_amt_last_y -- 借方金额_上年累计 FROM base_info_last WHERE (subject_code NOT like '660401%' AND subject_code NOT like '660403%' AND subject_code NOT like '660409%' AND subject_code NOT like '660408%' AND subject_code NOT like '660402%') ),tmp_data AS ( SELECT a.subject_name AS subject_name -- 科目名称 ,SUM(a.amt) AS amt FROM sdi_oth.ods_finance_budget_data a JOIN corp b on a.corp_name = b.corp_name WHERE fee_type = '研发费用' AND LEFT(years,4) = '${YEAR(sStart_mon)}' GROUP BY a.subject_name ) SELECT a.subject_name AS subject_name -- 科目名称 ,subject_code AS subject_code -- 科目编码 ,IFNULL(SUM(debit_amt_m ) / 10000,0) AS debit_amt_m -- 借方金额_当月累计 ,IFNULL(SUM(debit_amt_y ) / 10000,0) AS debit_amt_y -- 借方金额_当年累计 ,IFNULL(SUM(debit_amt_last_m) / 10000,0) AS debit_amt_last_m -- 借方金额_上年同期 ,IFNULL(SUM(debit_amt_last_y) / 10000,0) AS debit_amt_last_y -- 借方金额_上年累计 ,IFNULL(SUM(b.amt),0) AS debit_amt_yusuan FROM ( SELECT subject_name AS subject_name -- 科目名称 , subject_code AS subject_code -- 科目编码 , SUM(debit_amt_m) AS debit_amt_m -- 借方金额_当月累计 , SUM(debit_amt_y) AS debit_amt_y -- 借方金额_当年累计 , SUM(debit_amt_last_m) AS debit_amt_last_m -- 借方金额_上年同期 , SUM(debit_amt_last_y) AS debit_amt_last_y -- 借方金额_上年累计 FROM subject_result GROUP BY subject_name , subject_code )a LEFT JOIN tmp_data b ON a.subject_name = b.subject_name GROUP BY a.subject_name,subject_code ORDER BY DECODE(a.subject_name,'材料费','a','职工薪酬','b','差旅费','c','加工费','d','技术服务费','e','其他','f')