143 lines
5.4 KiB
SQL
143 lines
5.4 KiB
SQL
|
|
${if(p_type='人力',"","/*")}
|
|
|
|
SELECT
|
|
A.organ_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
|
|
A1.organ_code
|
|
,A1.organ_name
|
|
-- ${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
|
|
organ_code -- erp片区编码
|
|
,organ_name -- erp片区名称
|
|
,cost_comm_id
|
|
,cost_comm_name
|
|
FROM dim_organ_mapping_kunan_tmp
|
|
GROUP BY
|
|
organ_code
|
|
,organ_name
|
|
,cost_comm_id
|
|
,cost_comm_name
|
|
)A2
|
|
ON A1.organ_code = A2.organ_code
|
|
-- AND A1.dimsubjectcode = A2.cost_comm_id
|
|
WHERE 1=1
|
|
-- ${IF(LEN(p_area)>0," AND A2.id IN ('"+JOINARRAY(p_area,"','")+"')", "")}
|
|
GROUP BY
|
|
A1.organ_code
|
|
,A1.organ_name
|
|
-- ${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
|
|
organ_code
|
|
,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")}
|
|
organ_code
|
|
)B
|
|
ON A.organ_code = B.organ_code
|
|
|
|
${if(p_type='人力',"","*/")}
|
|
|
|
${if(p_type='行政',"","/*")}
|
|
|
|
|
|
|
|
SELECT
|
|
A.organ_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,"A2.comm_name", "A1.organ_name")} AS organ_comm_name
|
|
-- ${IF(LEN(p_area)>0,",A2.comm_id", ",A1.organ_code")} AS organ_comm_code
|
|
A1.organ_code
|
|
,A1.organ_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
|
|
organ_code -- erp片区编码
|
|
,organ_name -- erp片区名称
|
|
,comm_id
|
|
,comm_name
|
|
,cost_comm_id
|
|
,cost_comm_name
|
|
FROM dim_organ_mapping_kunan_tmp
|
|
GROUP BY
|
|
organ_code
|
|
,organ_name
|
|
,comm_id
|
|
,comm_name
|
|
,cost_comm_id
|
|
,cost_comm_name
|
|
)A2
|
|
ON A1.organ_code = A2.organ_code
|
|
-- AND A1.dimsubjectcode = A2.cost_comm_id
|
|
WHERE 1=1
|
|
-- ${IF(LEN(p_area)>0," AND A2.organ_code IN ('"+JOINARRAY(p_area,"','")+"')", "")}
|
|
GROUP BY
|
|
A1.organ_code
|
|
,A1.organ_name
|
|
-- ${IF(LEN(p_area)>0,"A2.comm_name", "A1.organ_name")}
|
|
-- ${IF(LEN(p_area)>0,",A2.comm_id", ",A1.organ_code")}
|
|
)A
|
|
LEFT JOIN
|
|
(-- 公司实际收入
|
|
SELECT
|
|
-- ${IF(LEN(p_area)>0,"comm_id", "organ_code")} AS organ_comm_code
|
|
organ_code
|
|
,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
|
|
organ_code
|
|
-- ${IF(LEN(p_area)>0,"comm_id", "organ_code")}
|
|
)B
|
|
ON A.organ_code = B.organ_code
|
|
|
|
${if(p_type='行政',"","*/")}
|
|
|