-- ====================================== -- 回款出货情况指标卡 -- 统计维度: 本月、本季度 -- 统计指标: 保底目标、实际达成、达成率 -- 同比、环比 -- ====================================== WITH base_data AS ( SELECT city_unit_code -- 城市单元编码 ,stat_date -- 统计时间 ,concat(year(stat_date),EXTRACT(QUARTER FROM stat_date)) AS stat_q -- 统计季度 ,CASE WHEN indi_type = '月度目标_城市单元_回款' THEN amt_city_unit ELSE 0 END AS payment_target_m -- 回款目标-月 ,CASE WHEN indi_type = '季度目标_城市单元_回款' THEN amt_city_unit ELSE 0 END AS payment_target_q -- 回款目标-季 ,CASE WHEN indi_type = '回款' THEN amt_city_unit ELSE 0 END AS payment -- 回款达成 ,CASE WHEN indi_type = '月度目标_城市单元_出货' THEN amt_city_unit ELSE 0 END AS ship_amt_target_m -- 出货目标-月 ,CASE WHEN indi_type = '季度目标_城市单元_出货' THEN amt_city_unit ELSE 0 END AS ship_amt_target_q -- 出货目标-季 ,CASE WHEN indi_type = '出货' THEN amt_city_unit ELSE 0 END AS ship_amt -- 出货达成 FROM dm.dm_sal_indicator_day a WHERE bu_code = '0202/0209' -- 电商KA AND indi_type in('回款','出货','季度目标_城市单元_出货','季度目标_城市单元_回款','月度目标_城市单元_出货','月度目标_城市单元_回款') ${if(len(sRegion) == 0,"","and region_code IN ('"+ sRegion+"')")} 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.bu_code -- 事业部 OR per_code = a.region_code -- 大区 OR per_code = a.office_code -- 城市单元 OR per_code = a.city_unit_code -- 城市单元 ) ) ) SELECT T.payment_target_m / 10000 AS payment_target_m -- 月度回款目标当期 ,T.yy_payment_target_m / 10000 AS yy_payment_target_m -- 月度回款目标同期 ,CASE WHEN yy_payment_target_m = 0 THEN 0 ELSE (T.payment_target_m - yy_payment_target_m) / ABS(yy_payment_target_m) END AS yyrate_payment_target_m -- 月度回款同比 ,T.mm_payment_target_m / 10000 AS mm_payment_target_m -- 月度回款目标往期 ,CASE WHEN mm_payment_target_m = 0 THEN 0 ELSE (T.payment_target_m - mm_payment_target_m) / ABS(mm_payment_target_m) END AS mmrate_payment_target_m -- 月度回款环比 ,T.payment_m / 10000 AS payment_m -- 月度回款达成当期 ,T.yy_payment_m / 10000 AS yy_payment_m -- 月度回款达成同期 ,CASE WHEN yy_payment_m = 0 THEN 0 ELSE (T.payment_m - yy_payment_m) / ABS(yy_payment_m) END AS yyrate_payment_m -- 月度回款达成同比 ,T.mm_payment_m / 10000 AS mm_payment_m -- 月度回款达成往期 ,CASE WHEN mm_payment_m = 0 THEN 0 ELSE (T.payment_m - mm_payment_m) / ABS(mm_payment_m) END AS mmrate_payment_m -- 月度回款达成环比 ,CASE WHEN T.payment_target_m = 0 THEN 0 ELSE (T.payment_m / T.payment_target_m) * 100 END AS payment_rate_m -- 月度回款达成率 ,CASE WHEN T.yy_payment_target_m = 0 THEN 0 ELSE (T.yy_payment_m / T.yy_payment_target_m) * 100 END AS yy_payment_rate_m -- 月度回款达成率同期 ,CASE WHEN T.mm_payment_target_m = 0 THEN 0 ELSE (T.mm_payment_m / T.mm_payment_target_m) * 100 END AS mm_payment_rate_m -- 月度回款达成率往期 ,T.payment_target_q / 10000 AS payment_target_q -- 季度回款目标当期 ,T.yy_payment_target_q / 10000 AS yy_payment_target_q -- 季度回款目标同期 ,CASE WHEN yy_payment_target_q = 0 THEN 0 ELSE (T.payment_target_q - yy_payment_target_q) / ABS(yy_payment_target_q) END AS yyrate_payment_target_q -- 季度回款目标同比 ,T.mm_payment_target_q / 10000 AS mm_payment_target_q -- 季度回款目标往期 ,CASE WHEN mm_payment_target_q = 0 THEN 0 ELSE (T.payment_target_q - mm_payment_target_q) / ABS(mm_payment_target_q) END AS mmrate_payment_target_q -- 季度回款目标环比 ,T.payment_q / 10000 AS payment_q -- 季度回款达成当期 ,T.yy_payment_q / 10000 AS yy_payment_q -- 季度回款达成同期 ,CASE WHEN yy_payment_q = 0 THEN 0 ELSE (T.payment_q - yy_payment_q) / ABS(yy_payment_q) END AS yyrate_payment_q -- 季度回款达成同比 ,T.mm_payment_q / 10000 AS mm_payment_q -- 季度回款达成往期 ,CASE WHEN mm_payment_q = 0 THEN 0 ELSE (T.payment_q - mm_payment_q) / ABS(mm_payment_q) END AS mmrate_payment_q -- 季度回款达成同比 ,CASE WHEN T.payment_target_q = 0 THEN 0 ELSE (T.payment_q / T.payment_target_q) * 100 END AS payment_rate_q -- 季度回款达成率 ,CASE WHEN T.yy_payment_target_q = 0 THEN 0 ELSE (T.yy_payment_q / T.yy_payment_target_q) * 100 END AS yy_payment_rate_q -- 季度回款达成率同期 ,CASE WHEN T.mm_payment_target_q = 0 THEN 0 ELSE (T.mm_payment_q / T.mm_payment_target_q) * 100 END AS mm_payment_rate_q -- 季度回款达成率往期 ,T.ship_amt_target_m / 10000 AS ship_amt_target_m -- 月度出货目标当期 ,T.yy_ship_amt_target_m / 10000 AS yy_ship_amt_target_m -- 月度出货目标同期 ,CASE WHEN T.yy_ship_amt_target_m = 0 THEN 0 ELSE (T.ship_amt_target_m - T.yy_ship_amt_target_m) / T.yy_ship_amt_target_m END AS yyrate_ship_amt_target_m -- 月度出货目标同比 ,T.mm_ship_amt_target_m / 10000 AS mm_ship_amt_target_m -- 月度出货目标往期 ,CASE WHEN T.mm_ship_amt_target_m = 0 THEN 0 ELSE (T.ship_amt_target_m - T.mm_ship_amt_target_m) / T.mm_ship_amt_target_m END AS mmrate_ship_amt_target_m -- 月度出货目标同比 ,T.ship_amt_m / 10000 AS ship_amt_m -- 月度出货达成当期 ,T.yy_ship_amt_m / 10000 AS yy_ship_amt_m -- 月度出货达成同期 ,CASE WHEN T.yy_ship_amt_m = 0 THEN 0 ELSE (T.ship_amt_m - T.yy_ship_amt_m) / ABS(T.yy_ship_amt_m) END AS yyrate_ship_amt_m -- 月度出货目标同比 ,T.mm_ship_amt_m / 10000 AS mm_ship_amt_m -- 月度出货达成往期 ,CASE WHEN T.mm_ship_amt_m = 0 THEN 0 ELSE (T.ship_amt_m - T.mm_ship_amt_m) / ABS(T.mm_ship_amt_m) END AS mmrate_ship_amt_m -- 月度出货目标同比 ,CASE WHEN T.ship_amt_target_m = 0 THEN 0 ELSE (T.ship_amt_m / T.ship_amt_target_m) * 100 END AS ship_rate_m -- 月度出货达成率 ,CASE WHEN T.yy_ship_amt_target_m = 0 THEN 0 ELSE (T.yy_ship_amt_m / T.yy_ship_amt_target_m) * 100 END AS yy_ship_rate_m -- 月度出货达成率同期 ,CASE WHEN T.mm_ship_amt_target_m = 0 THEN 0 ELSE (T.mm_ship_amt_m / T.mm_ship_amt_target_m) * 100 END AS mm_ship_rate_m -- 月度出货达成率往期 ,T.ship_amt_target_q / 10000 AS ship_amt_target_q -- 季度出货目标当期 ,T.yy_ship_amt_target_q / 10000 AS yy_ship_amt_target_q -- 季度出货目标同期 ,CASE WHEN T.yy_ship_amt_target_q = 0 THEN 0 ELSE (T.ship_amt_target_q - T.yy_ship_amt_target_q) / T.yy_ship_amt_target_q END AS yyrate_ship_amt_target_q -- 季度出货目标同比 ,T.mm_ship_amt_target_q / 10000 AS mm_ship_amt_target_q -- 季度出货目标往期 ,CASE WHEN T.mm_ship_amt_target_q = 0 THEN 0 ELSE (T.ship_amt_target_q - T.mm_ship_amt_target_q) / T.mm_ship_amt_target_q END AS mmrate_ship_amt_target_q -- 季度出货目标环比 ,T.ship_amt_q / 10000 AS ship_amt_q -- 季度出货达成当期 ,T.yy_ship_amt_q / 10000 AS yy_ship_amt_q -- 季度出货达成同期 ,CASE WHEN T.yy_ship_amt_q = 0 THEN 0 ELSE (T.ship_amt_q - T.yy_ship_amt_q) / ABS(T.yy_ship_amt_q) END AS yyrate_ship_amt_q -- 季度出货目标同比 ,T.mm_ship_amt_q / 10000 AS mm_ship_amt_q -- 季度出货达成往期 ,CASE WHEN T.mm_ship_amt_q = 0 THEN 0 ELSE (T.ship_amt_q - T.mm_ship_amt_q) / ABS(T.mm_ship_amt_q) END AS mmrate_ship_amt_q -- 季度出货目标同比 ,CASE WHEN T.ship_amt_target_q = 0 THEN 0 ELSE (T.ship_amt_q / T.ship_amt_target_q) * 100 END AS ship_rate_q -- 季度出货达成率 ,CASE WHEN T.yy_ship_amt_target_q = 0 THEN 0 ELSE (T.yy_ship_amt_q / T.yy_ship_amt_target_q) * 100 END AS yy_ship_rate_q -- 季度出货达成率同期 ,CASE WHEN T.mm_ship_amt_target_q = 0 THEN 0 ELSE (T.mm_ship_amt_q / T.mm_ship_amt_target_q) * 100 END AS mm_ship_rate_q -- 季度出货达成率往期 FROM ( SELECT -- 回款目标-月 SUM(CASE WHEN stat_date >= '${FORMAT(DATEINMONTH(sStart_date,1),"yyyy-MM-dd HH:mm:ss")}' AND stat_date <= '${FORMAT(sStart_date,"yyyy-MM-dd HH:mm:ss")}' THEN payment_target_m ELSE 0 END) AS payment_target_m -- 月度回款目标当期 ,SUM(CASE WHEN stat_date >= '${FORMAT(DATEINMONTH(YEARDELTA(sStart_date,-1),1),"yyyy-MM-dd HH:mm:ss")}' AND stat_date <= '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM-dd HH:mm:ss")}' THEN payment_target_m ELSE 0 END) AS yy_payment_target_m -- 月度回款目标同期 ,SUM(CASE WHEN stat_date >= '${FORMAT(DATEINMONTH(MONTHDELTA(sStart_date,-1),1),"yyyy-MM-dd HH:mm:ss")}' AND stat_date <= '${FORMAT(MONTHDELTA(sStart_date,-1),"yyyy-MM-dd HH:mm:ss")}' THEN payment_target_m ELSE 0 END) AS mm_payment_target_m -- 月度回款目标往期 -- 回款达成-月 ,SUM(CASE WHEN stat_date >= '${FORMAT(DATEINMONTH(sStart_date,1),"yyyy-MM-dd HH:mm:ss")}' AND stat_date <= '${FORMAT(sStart_date,"yyyy-MM-dd HH:mm:ss")}' THEN payment ELSE 0 END) AS payment_m -- 月度回款达成当期 ,SUM(CASE WHEN stat_date >= '${FORMAT(DATEINMONTH(YEARDELTA(sStart_date,-1),1),"yyyy-MM-dd HH:mm:ss")}' AND stat_date <= '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM-dd HH:mm:ss")}' THEN payment ELSE 0 END) AS yy_payment_m -- 月度回款达成同期 ,SUM(CASE WHEN stat_date >= '${FORMAT(DATEINMONTH(MONTHDELTA(sStart_date,-1),1),"yyyy-MM-dd HH:mm:ss")}' AND stat_date <= '${FORMAT(MONTHDELTA(sStart_date,-1),"yyyy-MM-dd HH:mm:ss")}' THEN payment ELSE 0 END) AS mm_payment_m -- 月度回款达成往期 -- 回款目标-季 ,SUM(CASE WHEN stat_q = '${CONCATENATE(left(sStart_date,4),roundup(month(sStart_date)/3))}' THEN payment_target_q ELSE 0 END) AS payment_target_q -- 季度回款目标当期 ,SUM(CASE WHEN stat_q = '${CONCATENATE(left(YEARDELTA(sStart_date,-1),4),roundup(month(YEARDELTA(sStart_date,-1))/3))}' THEN payment_target_q ELSE 0 END) AS yy_payment_target_q -- 季度回款目标同期 ,SUM(CASE WHEN stat_q = '${CONCATENATE(left(sStart_date,4),(IF(roundup(month(sStart_date)/3)=1,4,roundup(month(sStart_date)/3) - 1)))}' THEN payment_target_q ELSE 0 END) AS mm_payment_target_q -- 季度回款目标往期 -- 回款达成-季 ,SUM(CASE WHEN stat_q = '${CONCATENATE(left(sStart_date,4),roundup(month(sStart_date)/3))}' AND stat_date <= '${FORMAT(sStart_date,"yyyy-MM-dd HH:mm:ss")}' THEN payment ELSE 0 END) AS payment_q -- 季度回款达成当期 ,SUM(CASE WHEN stat_q = '${CONCATENATE(left(YEARDELTA(sStart_date,-1),4),roundup(month(YEARDELTA(sStart_date,-1))/3))}' AND stat_date <= '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM-dd HH:mm:ss")}' THEN payment ELSE 0 END) AS yy_payment_q -- 季度回款达成同期 -- DATEINQUARTER(date,1) 获取当前时间季度开始的月份的第一天 ,SUM(CASE WHEN stat_q = '${CONCATENATE(left(sStart_date,4),(IF(roundup(month(sStart_date)/3)=1,4,roundup(month(sStart_date)/3) - 1)))}' -- AND stat_date <= '${FORMAT(MONTHDELTA(sStart_date,-4),"yyyy-MM-dd HH:mm:ss")}' THEN payment ELSE 0 END) AS mm_payment_q -- 季度回款达成往期 -- 出货目标-月 ,SUM(CASE WHEN stat_date >= '${FORMAT(DATEINMONTH(sStart_date,1),"yyyy-MM-dd HH:mm:ss")}' AND stat_date <= '${FORMAT(sStart_date,"yyyy-MM-dd HH:mm:ss")}' THEN ship_amt_target_m ELSE 0 END) AS ship_amt_target_m -- 月度出货目标当期 ,SUM(CASE WHEN stat_date >= '${FORMAT(DATEINMONTH(YEARDELTA(sStart_date,-1),1),"yyyy-MM-dd HH:mm:ss")}' AND stat_date <= '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM-dd HH:mm:ss")}' THEN ship_amt_target_m ELSE 0 END) AS yy_ship_amt_target_m -- 月度出货目标同期 ,SUM(CASE WHEN stat_date >= '${FORMAT(DATEINMONTH(MONTHDELTA(sStart_date,-1),1),"yyyy-MM-dd HH:mm:ss")}' AND stat_date <= '${FORMAT(MONTHDELTA(sStart_date,-1),"yyyy-MM-dd HH:mm:ss")}' THEN ship_amt_target_m ELSE 0 END) AS mm_ship_amt_target_m -- 月度出货目标往期 -- 出货达成-月 ,SUM(CASE WHEN stat_date >= '${FORMAT(DATEINMONTH(sStart_date,1),"yyyy-MM-dd HH:mm:ss")}' AND stat_date <= '${FORMAT(sStart_date,"yyyy-MM-dd HH:mm:ss")}' THEN ship_amt ELSE 0 END) AS ship_amt_m -- 月度出货达成当期 ,SUM(CASE WHEN stat_date >= '${FORMAT(DATEINMONTH(YEARDELTA(sStart_date,-1),1),"yyyy-MM-dd HH:mm:ss")}' AND stat_date <= '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM-dd HH:mm:ss")}' THEN ship_amt ELSE 0 END) AS yy_ship_amt_m -- 月度出货达成同期 ,SUM(CASE WHEN stat_date >= '${FORMAT(DATEINMONTH(MONTHDELTA(sStart_date,-1),1),"yyyy-MM-dd HH:mm:ss")}' AND stat_date <= '${FORMAT(MONTHDELTA(sStart_date,-1),"yyyy-MM-dd HH:mm:ss")}' THEN ship_amt ELSE 0 END) AS mm_ship_amt_m -- 月度出货达成往期 -- 出货目标-季 ,SUM(CASE WHEN stat_q = '${CONCATENATE(left(sStart_date,4),roundup(month(sStart_date)/3))}' THEN ship_amt_target_q ELSE 0 END) AS ship_amt_target_q -- 季度出货目标当期 ,SUM(CASE WHEN stat_q = '${CONCATENATE(left(YEARDELTA(sStart_date,-1),4),roundup(month(YEARDELTA(sStart_date,-1))/3))}' THEN ship_amt_target_q ELSE 0 END) AS yy_ship_amt_target_q -- 季度出货目标同期 ,SUM(CASE WHEN stat_q = '${CONCATENATE(left(sStart_date,4),(IF(roundup(month(sStart_date)/3)=1,4,roundup(month(sStart_date)/3) - 1)))}' THEN ship_amt_target_q ELSE 0 END) AS mm_ship_amt_target_q -- 季度出货目标往期 -- 出货达成-季 ,SUM(CASE WHEN stat_q = '${CONCATENATE(left(sStart_date,4),roundup(month(sStart_date)/3))}' AND stat_date <= '${FORMAT(sStart_date,"yyyy-MM-dd HH:mm:ss")}' THEN ship_amt ELSE 0 END) AS ship_amt_q -- 季度出货达成当期 ,SUM(CASE WHEN stat_q = '${CONCATENATE(left(YEARDELTA(sStart_date,-1),4),roundup(month(YEARDELTA(sStart_date,-1))/3))}' AND stat_date <= '${FORMAT(YEARDELTA(sStart_date,-1),"yyyy-MM-dd HH:mm:ss")}' THEN ship_amt ELSE 0 END) AS yy_ship_amt_q -- 季度出货达成同期 -- DATEINQUARTER(date,1) 获取当前时间季度开始的月份的第一天 ,SUM(CASE WHEN stat_q = '${CONCATENATE(left(sStart_date,4),(IF(roundup(month(sStart_date)/3)=1,4,roundup(month(sStart_date)/3) - 1)))}' -- AND stat_date <= '${FORMAT(MONTHDELTA(sStart_date,-4),"yyyy-MM-dd HH:mm:ss")}' THEN ship_amt ELSE 0 END) AS mm_ship_amt_q -- 季度出货达成往期 FROM base_data )T ; -- ====================================== -- 回款情况排名 -- 统计时间维度: 月度、季度 -- 维度: 城市单元+负责人 -- 指标: 保底目标、实际达成、达成比、排名 -- ====================================== WITH base_data AS ( SELECT city_unit_code -- 城市单元编码 ,dmd.dept_name as city_unit_name -- 城市单元名称 ,stat_date -- 统计时间 ,concat(year(stat_date),EXTRACT(QUARTER FROM stat_date)) AS stat_q -- 统计季度 ,CASE WHEN indi_type = '月度目标_城市单元_回款' THEN amt_city_unit ELSE 0 END AS payment_target_m -- 回款目标-月 ,CASE WHEN indi_type = '季度目标_城市单元_回款' THEN amt_city_unit ELSE 0 END AS payment_target_q -- 回款目标-季 ,CASE WHEN indi_type = '回款' THEN amt_city_unit ELSE 0 END AS payment -- 回款达成 ,CASE WHEN indi_type = '月度目标_城市单元_出货' THEN amt_city_unit ELSE 0 END AS ship_amt_target_m -- 出货目标-月 ,CASE WHEN indi_type = '季度目标_城市单元_出货' THEN amt_city_unit ELSE 0 END AS ship_amt_target_q -- 出货目标-季 ,CASE WHEN indi_type = '出货' THEN amt_city_unit ELSE 0 END AS ship_amt -- 出货达成 FROM dm.dm_sal_indicator_day a LEFT JOIN dwr.dim_department dmd on a.city_unit_code=dmd.dept_code WHERE bu_code = '0202/0209' -- 电商KA AND indi_type in('回款','出货','季度目标_城市单元_出货','季度目标_城市单元_回款','月度目标_城市单元_出货','月度目标_城市单元_回款') ${if(len(sRegion) == 0,"","and region_code IN ('"+ sRegion+"')")} 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.bu_code -- 事业部 OR per_code = a.region_code -- 大区 OR per_code = a.office_code -- 城市单元 OR per_code = a.city_unit_code -- 城市单元 ) ) AND dmd.dept_name not LIKE '%停用%' ), base_date2 AS( SELECT T.city_unit_name AS city_unit_name ,T.payment_target_m / 10000 AS payment_target_m -- 月度回款目标当期 ,T.payment_m / 10000 AS payment_m -- 月度回款达成当期 ,CASE WHEN T.payment_target_m = 0 THEN 0 ELSE T.payment_m / T.payment_target_m END AS payment_rate_m -- 月度回款达成率 ,T.payment_target_q / 10000 AS payment_target_q -- 季度回款目标当期 ,T.payment_q / 10000 AS payment_q -- 季度回款达成当期 ,CASE WHEN T.payment_target_q = 0 THEN 0 ELSE T.payment_q / T.payment_target_q END AS payment_rate_q -- 季度回款达成率 ,T.ship_amt_target_m / 10000 AS ship_amt_target_m -- 月度出货目标当期 ,T.ship_amt_m / 10000 AS ship_amt_m -- 月度出货达成当期 ,CASE WHEN T.ship_amt_target_m = 0 THEN 0 ELSE T.ship_amt_m / T.ship_amt_target_m END AS ship_rate_m -- 月度出货达成率 ,T.ship_amt_target_q / 10000 AS ship_amt_target_q -- 季度出货目标当期 ,T.ship_amt_q / 10000 AS ship_amt_q -- 季度出货达成当期 ,CASE WHEN T.ship_amt_target_q = 0 THEN 0 ELSE T.ship_amt_q / T.ship_amt_target_q END AS ship_rate_q -- 季度出货达成率 FROM ( SELECT city_unit_name -- 回款目标-月 ,SUM(CASE WHEN stat_date >= '${FORMAT(DATEINMONTH(sStart_date,1),"yyyy-MM-dd HH:mm:ss")}' AND stat_date <= '${FORMAT(sStart_date,"yyyy-MM-dd HH:mm:ss")}' THEN payment_target_m ELSE 0 END) AS payment_target_m -- 月度回款目标当期 -- 回款达成-月 ,SUM(CASE WHEN stat_date >= '${FORMAT(DATEINMONTH(sStart_date,1),"yyyy-MM-dd HH:mm:ss")}' AND stat_date <= '${FORMAT(sStart_date,"yyyy-MM-dd HH:mm:ss")}' THEN payment ELSE 0 END) AS payment_m -- 月度回款达成当期 -- 回款目标-季 ,SUM(CASE WHEN stat_q = '${CONCATENATE(left(sStart_date,4),roundup(month(sStart_date)/3))}' THEN payment_target_q ELSE 0 END) AS payment_target_q -- 季度回款目标当期 -- 回款达成-季 ,SUM(CASE WHEN stat_q = '${CONCATENATE(left(sStart_date,4),roundup(month(sStart_date)/3))}' AND stat_date <= '${FORMAT(sStart_date,"yyyy-MM-dd HH:mm:ss")}' THEN payment ELSE 0 END) AS payment_q -- 季度回款达成当期 -- 出货目标-月 ,SUM(CASE WHEN stat_date >= '${FORMAT(DATEINMONTH(sStart_date,1),"yyyy-MM-dd HH:mm:ss")}' AND stat_date <= '${FORMAT(sStart_date,"yyyy-MM-dd HH:mm:ss")}' THEN ship_amt_target_m ELSE 0 END) AS ship_amt_target_m -- 月度出货目标当期 -- 出货达成-月 ,SUM(CASE WHEN stat_date >= '${FORMAT(DATEINMONTH(sStart_date,1),"yyyy-MM-dd HH:mm:ss")}' AND stat_date <= '${FORMAT(sStart_date,"yyyy-MM-dd HH:mm:ss")}' THEN ship_amt ELSE 0 END) AS ship_amt_m -- 月度出货达成当期 -- 出货目标-季 ,SUM(CASE WHEN stat_q = '${CONCATENATE(left(sStart_date,4),roundup(month(sStart_date)/3))}' THEN ship_amt_target_q ELSE 0 END) AS ship_amt_target_q -- 季度出货目标当期 -- 出货达成-季 ,SUM(CASE WHEN stat_q = '${CONCATENATE(left(sStart_date,4),roundup(month(sStart_date)/3))}' AND stat_date <= '${FORMAT(sStart_date,"yyyy-MM-dd HH:mm:ss")}' THEN ship_amt ELSE 0 END) AS ship_amt_q -- 季度出货达成当期 FROM base_data GROUP BY city_unit_name )T ) SELECT * FROM ( SELECT city_unit_name , ROUND(payment_target_m,4) AS payment_target_m , ROUND(payment_m,4) AS payment_m , payment_rate_m , row_number() OVER (ORDER BY payment_rate_m DESC ) AS rate_m_rk , ROUND(payment_target_q,4) AS payment_target_q , ROUND(payment_q,4) AS payment_q , payment_rate_q , row_number() OVER (ORDER BY payment_rate_q DESC ) AS rate_q_rk , ROUND(ship_amt_target_m,4) AS ship_amt_target_m , ROUND(ship_amt_m,4) AS ship_amt_m , ship_rate_m , ROUND(ship_amt_target_q,4) AS ship_amt_target_q , ROUND(ship_amt_q,4) AS ship_amt_q , ship_rate_q FROM base_date2 )T ORDER BY rate_m_rk LIMIT 8 ; -- ====================================== -- 出货情况排名 -- 统计时间维度: 月度、季度 -- 维度: 城市单元+负责人 -- 指标: 保底目标、实际达成、达成比、排名 -- ====================================== WITH base_data AS ( SELECT city_unit_code -- 城市单元编码 ,dmd.dept_name as city_unit_name -- 城市单元名称 ,stat_date -- 统计时间 ,concat(year(stat_date),EXTRACT(QUARTER FROM stat_date)) AS stat_q -- 统计季度 ,CASE WHEN indi_type = '月度目标_城市单元_回款' THEN amt_city_unit ELSE 0 END AS payment_target_m -- 回款目标-月 ,CASE WHEN indi_type = '季度目标_城市单元_回款' THEN amt_city_unit ELSE 0 END AS payment_target_q -- 回款目标-季 ,CASE WHEN indi_type = '回款' THEN amt_city_unit ELSE 0 END AS payment -- 回款达成 ,CASE WHEN indi_type = '月度目标_城市单元_出货' THEN amt_city_unit ELSE 0 END AS ship_amt_target_m -- 出货目标-月 ,CASE WHEN indi_type = '季度目标_城市单元_出货' THEN amt_city_unit ELSE 0 END AS ship_amt_target_q -- 出货目标-季 ,CASE WHEN indi_type = '出货' THEN amt_city_unit ELSE 0 END AS ship_amt -- 出货达成 FROM dm.dm_sal_indicator_day a LEFT JOIN dwr.dim_department dmd on a.city_unit_code=dmd.dept_code WHERE bu_code = '0202/0209' -- 电商KA AND indi_type in('回款','出货','季度目标_城市单元_出货','季度目标_城市单元_回款','月度目标_城市单元_出货','月度目标_城市单元_回款') ${if(len(sRegion) == 0,"","and region_code IN ('"+ sRegion+"')")} 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.bu_code -- 事业部 OR per_code = a.region_code -- 大区 OR per_code = a.office_code -- 城市单元 OR per_code = a.city_unit_code -- 城市单元 ) ) AND dmd.dept_name not LIKE '%停用%' ), base_date2 AS( SELECT T.city_unit_name AS city_unit_name ,T.payment_target_m / 10000 AS payment_target_m -- 月度回款目标当期 ,T.payment_m / 10000 AS payment_m -- 月度回款达成当期 ,CASE WHEN T.payment_target_m = 0 THEN 0 ELSE T.payment_m / T.payment_target_m END AS payment_rate_m -- 月度回款达成率 ,T.payment_target_q / 10000 AS payment_target_q -- 季度回款目标当期 ,T.payment_q / 10000 AS payment_q -- 季度回款达成当期 ,CASE WHEN T.payment_target_q = 0 THEN 0 ELSE T.payment_q / T.payment_target_q END AS payment_rate_q -- 季度回款达成率 ,T.ship_amt_target_m / 10000 AS ship_amt_target_m -- 月度出货目标当期 ,T.ship_amt_m / 10000 AS ship_amt_m -- 月度出货达成当期 ,CASE WHEN T.ship_amt_target_m = 0 THEN 0 ELSE T.ship_amt_m / T.ship_amt_target_m END AS ship_rate_m -- 月度出货达成率 ,T.ship_amt_target_q / 10000 AS ship_amt_target_q -- 季度出货目标当期 ,T.ship_amt_q / 10000 AS ship_amt_q -- 季度出货达成当期 ,CASE WHEN T.ship_amt_target_q = 0 THEN 0 ELSE T.ship_amt_q / T.ship_amt_target_q END AS ship_rate_q -- 季度出货达成率 FROM ( SELECT city_unit_name -- 回款目标-月 ,SUM(CASE WHEN stat_date >= '${FORMAT(DATEINMONTH(sStart_date,1),"yyyy-MM-dd HH:mm:ss")}' AND stat_date <= '${FORMAT(sStart_date,"yyyy-MM-dd HH:mm:ss")}' THEN payment_target_m ELSE 0 END) AS payment_target_m -- 月度回款目标当期 -- 回款达成-月 ,SUM(CASE WHEN stat_date >= '${FORMAT(DATEINMONTH(sStart_date,1),"yyyy-MM-dd HH:mm:ss")}' AND stat_date <= '${FORMAT(sStart_date,"yyyy-MM-dd HH:mm:ss")}' THEN payment ELSE 0 END) AS payment_m -- 月度回款达成当期 -- 回款目标-季 ,SUM(CASE WHEN stat_q = '${CONCATENATE(left(sStart_date,4),roundup(month(sStart_date)/3))}' THEN payment_target_q ELSE 0 END) AS payment_target_q -- 季度回款目标当期 -- 回款达成-季 ,SUM(CASE WHEN stat_q = '${CONCATENATE(left(sStart_date,4),roundup(month(sStart_date)/3))}' AND stat_date <= '${FORMAT(sStart_date,"yyyy-MM-dd HH:mm:ss")}' THEN payment ELSE 0 END) AS payment_q -- 季度回款达成当期 -- 出货目标-月 ,SUM(CASE WHEN stat_date >= '${FORMAT(DATEINMONTH(sStart_date,1),"yyyy-MM-dd HH:mm:ss")}' AND stat_date <= '${FORMAT(sStart_date,"yyyy-MM-dd HH:mm:ss")}' THEN ship_amt_target_m ELSE 0 END) AS ship_amt_target_m -- 月度出货目标当期 -- 出货达成-月 ,SUM(CASE WHEN stat_date >= '${FORMAT(DATEINMONTH(sStart_date,1),"yyyy-MM-dd HH:mm:ss")}' AND stat_date <= '${FORMAT(sStart_date,"yyyy-MM-dd HH:mm:ss")}' THEN ship_amt ELSE 0 END) AS ship_amt_m -- 月度出货达成当期 -- 出货目标-季 ,SUM(CASE WHEN stat_q = '${CONCATENATE(left(sStart_date,4),roundup(month(sStart_date)/3))}' THEN ship_amt_target_q ELSE 0 END) AS ship_amt_target_q -- 季度出货目标当期 -- 出货达成-季 ,SUM(CASE WHEN stat_q = '${CONCATENATE(left(sStart_date,4),roundup(month(sStart_date)/3))}' AND stat_date <= '${FORMAT(sStart_date,"yyyy-MM-dd HH:mm:ss")}' THEN ship_amt ELSE 0 END) AS ship_amt_q -- 季度出货达成当期 FROM base_data GROUP BY city_unit_name )T ) SELECT * FROM ( SELECT city_unit_name , ROUND(payment_target_m,4) AS payment_target_m , ROUND(payment_m,4) AS payment_m , ROUND(payment_rate_m,4) AS payment_rate_m , ROUND(payment_target_q,4) ASpayment_target_q , ROUND(payment_q,4) AS payment_q , payment_rate_q , ROUND(ship_amt_target_m,4) AS ship_amt_target_m , ROUND(ship_amt_m,4) AS ship_amt_m , ship_rate_m , row_number() OVER (ORDER BY ship_rate_m DESC ) AS rate_m_rk , ROUND(ship_amt_target_q,4) AS ship_amt_target_q , ROUND(ship_amt_q,4) AS ship_amt_q , ship_rate_q , row_number() OVER (ORDER BY ship_rate_q DESC ) AS rate_q_rk FROM base_date2 )T ORDER BY rate_m_rk LIMIT 8 ; -- ====================================== -- 数据处理时间 -- ====================================== SELECT concat('数据处理时间:',MAX(update_time) )AS update_time FROM dwr.fact_sal_eorder