213 lines
9.5 KiB
MySQL
213 lines
9.5 KiB
MySQL
|
-- 【report_指标卡_填报】
|
||
|
|
||
|
SELECT
|
||
|
-- 收入汇总费用
|
||
|
SUM(CASE WHEN business_type = '收入' THEN COALESCE(revenue_value,0) ELSE 0 END) as revenue_value -- 四大业务收入
|
||
|
,SUM(CASE WHEN revenue_type = '附属' AND business_type = '收入' THEN COALESCE(revenue_value,0) ELSE 0 END) AS revenue_value_1 -- 空间运营收入
|
||
|
,SUM(CASE WHEN revenue_type = '拎包' AND business_type = '收入' THEN COALESCE(revenue_value,0) ELSE 0 END) AS revenue_value_2 -- 美居收入
|
||
|
,SUM(CASE WHEN revenue_type = '创新' AND business_type = '收入' THEN COALESCE(revenue_value,0) ELSE 0 END) AS revenue_value_3 -- 新零售收入
|
||
|
,SUM(CASE WHEN revenue_type = '资产' AND business_type = '收入' THEN COALESCE(revenue_value,0) ELSE 0 END) AS revenue_value_4 -- 资产出租收入
|
||
|
|
||
|
-- 收入完成率
|
||
|
,CASE WHEN SUM(CASE WHEN business_type = '目标' THEN COALESCE(revenue_value,0) ELSE 0 END) = 0 THEN 0
|
||
|
ELSE SUM(CASE WHEN business_type = '收入' THEN COALESCE(revenue_value,0) ELSE 0 END)
|
||
|
/ SUM(CASE WHEN business_type = '目标' THEN COALESCE(revenue_value,0) ELSE 0 END)
|
||
|
END AS finish_rate -- 四大业务收入完成率
|
||
|
|
||
|
,CASE WHEN SUM(CASE WHEN revenue_type = '附属' AND business_type = '目标' THEN COALESCE(revenue_value,0) ELSE 0 END) = 0 THEN 0
|
||
|
ELSE SUM(CASE WHEN revenue_type = '附属' AND business_type = '收入' THEN COALESCE(revenue_value,0) ELSE 0 END)
|
||
|
/ SUM(CASE WHEN revenue_type = '附属' AND business_type = '目标' THEN COALESCE(revenue_value,0) ELSE 0 END)
|
||
|
END AS finish_rate_1 -- 空间运营收入完成率
|
||
|
|
||
|
,CASE WHEN SUM(CASE WHEN revenue_type = '拎包' AND business_type = '目标' THEN COALESCE(revenue_value,0) ELSE 0 END) = 0 THEN 0
|
||
|
ELSE SUM(CASE WHEN revenue_type = '拎包' AND business_type = '收入' THEN COALESCE(revenue_value,0) ELSE 0 END)
|
||
|
/ SUM(CASE WHEN revenue_type = '拎包' AND business_type = '目标' THEN COALESCE(revenue_value,0) ELSE 0 END)
|
||
|
END AS finish_rate_2 -- 美居收入完成率
|
||
|
|
||
|
,CASE WHEN SUM(CASE WHEN revenue_type = '创新' AND business_type = '目标' THEN COALESCE(revenue_value,0) ELSE 0 END) = 0 THEN 0
|
||
|
ELSE SUM(CASE WHEN revenue_type = '创新' AND business_type = '收入' THEN COALESCE(revenue_value,0) ELSE 0 END)
|
||
|
/ SUM(CASE WHEN revenue_type = '创新' AND business_type = '目标' THEN COALESCE(revenue_value,0) ELSE 0 END)
|
||
|
END AS finish_rate_3 -- 新零售收入完成率
|
||
|
|
||
|
,CASE WHEN SUM(CASE WHEN revenue_type = '资产' AND business_type = '目标' THEN COALESCE(revenue_value,0) ELSE 0 END) = 0 THEN 0
|
||
|
ELSE SUM(CASE WHEN revenue_type = '资产' AND business_type = '收入' THEN COALESCE(revenue_value,0) ELSE 0 END)
|
||
|
/ SUM(CASE WHEN revenue_type = '资产' AND business_type = '目标' THEN COALESCE(revenue_value,0) ELSE 0 END)
|
||
|
END AS finish_rate_4 -- 资产出租收入完成率
|
||
|
|
||
|
FROM dw.ods_innoveco_metrics_finish_d
|
||
|
WHERE business_type in('收入','目标') -- 业务类型
|
||
|
AND YM = '${p_ym}'
|
||
|
${IF(LEN(p_area)>0," AND organ_code IN ('"+JOINARRAY(p_area,"','")+"')", "")}
|
||
|
;
|
||
|
|
||
|
|
||
|
-- report_指标卡
|
||
|
|
||
|
|
||
|
WITH T1 AS (/*各类别应收与实收*/
|
||
|
SELECT
|
||
|
index_type,
|
||
|
SUM(IFNULL(index_receivable,0)) AS 应收金额,
|
||
|
SUM(IFNULL(index_receipts,0)) AS 实收金额
|
||
|
FROM ods_caiwu_profit
|
||
|
WHERE 1=1
|
||
|
-- AND `year_month` = '${REPLACE(p_ym,"-","")}'
|
||
|
-- ${IF(LEN(p_area)>0," AND organ_code IN ('"+JOINARRAY(p_area,"','")+"')", "")}
|
||
|
-- ${IF(LEN(p_prgject)>0," AND comm_id IN ('"+JOINARRAY(p_prgject,"','")+"')", "")}
|
||
|
GROUP BY index_type
|
||
|
)
|
||
|
SELECT
|
||
|
SUM(CASE WHEN index_type = '附属资源/空间运营' THEN 实收金额 ELSE 0 END) AS 空间运营实收,
|
||
|
SUM(CASE WHEN index_type = '附属资源/空间运营' THEN 实收金额 / 应收金额 ELSE 0 END) AS 空间运营完成率,
|
||
|
SUM(CASE WHEN index_type = '美居' THEN 实收金额 ELSE 0 END) AS 美居实收,
|
||
|
SUM(CASE WHEN index_type = '美居' THEN 实收金额 / 应收金额 ELSE 0 END) AS 美居完成率,
|
||
|
SUM(CASE WHEN index_type = '社商/新零售' THEN 实收金额 ELSE 0 END) AS 新零售实收,
|
||
|
SUM(CASE WHEN index_type = '社商/新零售' THEN 实收金额 / 应收金额 ELSE 0 END) AS 新零售完成率,
|
||
|
SUM(CASE WHEN index_type = '资产运营/资产租售' THEN 实收金额 ELSE 0 END) AS 资产出租实收,
|
||
|
SUM(CASE WHEN index_type = '资产运营/资产租售' THEN 实收金额 / 应收金额 ELSE 0 END) AS 资产出租完成率,
|
||
|
SUM(实收金额) AS 全部实收,
|
||
|
IFNULL(SUM(实收金额) / SUM(应收金额),0) AS 完成率
|
||
|
FROM T1
|
||
|
;
|
||
|
-- ======================================
|
||
|
-- 表格_2_新零售大于50_new
|
||
|
-- ======================================
|
||
|
|
||
|
SELECT
|
||
|
T1.organ_comm_name AS organ_name
|
||
|
,T1.FINISH_RATE AS 销售完成率
|
||
|
,T1.sale_target AS sale_target
|
||
|
,T1.sale_amt AS sale_amt
|
||
|
,ROW_NUMBER() OVER (ORDER BY T1.FINISH_RATE DESC) AS 序号
|
||
|
FROM
|
||
|
(
|
||
|
SELECT
|
||
|
-- B.organ_code
|
||
|
-- ,B.organ_name
|
||
|
-- ,B.comm_id
|
||
|
-- ,B.comm_name
|
||
|
${IF(LEN(p_area)>0,"B.comm_name", "B.organ_name")} AS organ_comm_name
|
||
|
-- ,SUM(B.sale_target) AS sale_target
|
||
|
,SUM(IFNULL(A.sale_amt,0)) + SUM(IFNULL(B.sale_fact,0)) AS sale_amt
|
||
|
,SUM(IFNULL(B.sale_target,0)) AS sale_target
|
||
|
,CASE WHEN SUM(IFNULL(B.sale_target,0)) = 0 THEN 0
|
||
|
ELSE SUM(IFNULL(A.sale_amt,0)) + SUM(IFNULL(B.sale_fact,0)) / SUM(IFNULL
|
||
|
(B.sale_target,0))
|
||
|
END AS FINISH_RATE -- 销售完成率
|
||
|
FROM
|
||
|
(
|
||
|
select
|
||
|
organ_code
|
||
|
,organ_name
|
||
|
,comm_id
|
||
|
,comm_name
|
||
|
,sum(case when create_ym = '202406' then 0 else sale_amt end) sale_amt -- 202406填报数据为线下+线下,所以不取线上数据
|
||
|
from dw.dws_innoveco_new_retail_m
|
||
|
where create_ym = '${REPLACE(p_ym,"-","")}'
|
||
|
group by
|
||
|
organ_code
|
||
|
,organ_name
|
||
|
,comm_id
|
||
|
,comm_name
|
||
|
)A
|
||
|
RIGHT JOIN
|
||
|
(
|
||
|
SELECT
|
||
|
organ_code
|
||
|
,organ_name
|
||
|
,comm_id
|
||
|
,comm_name
|
||
|
,SUM(IFNULL(index_retail_target,0))*10000 AS sale_target
|
||
|
,SUM(index_retail_fact)*10000 AS sale_fact
|
||
|
FROM dw.ods_innoveco_offlinesales
|
||
|
WHERE `year_month` = '${REPLACE(p_ym,"-","")}'
|
||
|
GROUP BY
|
||
|
organ_code
|
||
|
,organ_name
|
||
|
,comm_id
|
||
|
,comm_name
|
||
|
)B
|
||
|
ON A.organ_code = B.organ_code
|
||
|
AND A.comm_id = B.comm_id
|
||
|
WHERE 1=1
|
||
|
${IF(LEN(p_area)>0," AND B.organ_code IN ('"+JOINARRAY(p_area,"','")+"')", "")}
|
||
|
GROUP BY
|
||
|
${IF(LEN(p_area)>0,"B.comm_name", "B.organ_name")}
|
||
|
)T1
|
||
|
ORDER BY T1.FINISH_RATE DESC
|
||
|
LIMIT 5
|
||
|
|
||
|
|
||
|
-- ======================================
|
||
|
-- 表格_2_新零售小于50_new
|
||
|
-- ======================================
|
||
|
|
||
|
|
||
|
SELECT
|
||
|
T1.organ_comm_name AS organ_name
|
||
|
,T1.FINISH_RATE AS 销售完成率
|
||
|
,T1.sale_target AS sale_target
|
||
|
,T1.sale_amt AS sale_amt
|
||
|
,ROW_NUMBER() OVER (ORDER BY T1.FINISH_RATE ASC) AS 序号
|
||
|
FROM
|
||
|
(
|
||
|
SELECT
|
||
|
-- B.organ_code
|
||
|
-- ,B.organ_name
|
||
|
-- ,B.comm_id
|
||
|
-- ,B.comm_name
|
||
|
${IF(LEN(p_area)>0,"B.comm_name", "B.organ_name")} AS organ_comm_name
|
||
|
-- ,SUM(B.sale_target) AS sale_target
|
||
|
,SUM(IFNULL(A.sale_amt,0)) + SUM(IFNULL(B.sale_fact,0)) AS sale_amt
|
||
|
,SUM(IFNULL(B.sale_target,0)) AS sale_target
|
||
|
,CASE WHEN SUM(IFNULL(B.sale_target,0)) = 0 THEN 0
|
||
|
ELSE SUM(IFNULL(A.sale_amt,0)) + SUM(IFNULL(B.sale_fact,0)) / SUM(IFNULL
|
||
|
(B.sale_target,0))
|
||
|
END AS FINISH_RATE -- 销售完成率
|
||
|
FROM
|
||
|
(
|
||
|
select
|
||
|
organ_code
|
||
|
,organ_name
|
||
|
,comm_id
|
||
|
,comm_name
|
||
|
,sum(case when create_ym = '202406' then 0 else sale_amt end) sale_amt -- 202406填报数据为线下+线下,所以不取线上数据
|
||
|
from dw.dws_innoveco_new_retail_m
|
||
|
where create_ym = '${REPLACE(p_ym,"-","")}'
|
||
|
group by
|
||
|
organ_code
|
||
|
,organ_name
|
||
|
,comm_id
|
||
|
,comm_name
|
||
|
)A
|
||
|
RIGHT JOIN
|
||
|
(
|
||
|
SELECT
|
||
|
organ_code
|
||
|
,organ_name
|
||
|
,comm_id
|
||
|
,comm_name
|
||
|
,SUM(IFNULL(index_retail_target,0))*10000 AS sale_target
|
||
|
,SUM(index_retail_fact)*10000 AS sale_fact
|
||
|
FROM dw.ods_innoveco_offlinesales
|
||
|
WHERE `year_month` = '${REPLACE(p_ym,"-","")}'
|
||
|
GROUP BY
|
||
|
organ_code
|
||
|
,organ_name
|
||
|
,comm_id
|
||
|
,comm_name
|
||
|
)B
|
||
|
ON A.organ_code = B.organ_code
|
||
|
AND A.comm_id = B.comm_id
|
||
|
WHERE 1=1
|
||
|
${IF(LEN(p_area)>0," AND B.organ_code IN ('"+JOINARRAY(p_area,"','")+"')", "")}
|
||
|
GROUP BY
|
||
|
${IF(LEN(p_area)>0,"B.comm_name", "B.organ_name")}
|
||
|
)T1
|
||
|
ORDER BY T1.FINISH_RATE ASC
|
||
|
LIMIT 5
|
||
|
|
||
|
|
||
|
-- ======================================
|
||
|
--
|
||
|
-- ======================================
|