From 078a1485443b73593f8a2f3815d0d2a6af202700 Mon Sep 17 00:00:00 2001 From: yangkunan Date: Tue, 10 Dec 2024 13:57:49 +0800 Subject: [PATCH] =?UTF-8?q?=E7=94=B5=E5=95=86KA=E7=9C=8B=E6=9D=BF=E6=96=B0?= =?UTF-8?q?=E5=A2=9E=E5=A4=A7=E5=8C=BA=E7=AD=9B=E9=80=89+=E9=A6=96?= =?UTF-8?q?=E9=A1=B5=E7=9C=8B=E6=9D=BF=E6=96=B0=E5=A2=9E=E5=BA=93=E5=AD=98?= =?UTF-8?q?=E6=8C=87=E6=A0=87+=E8=90=A5=E9=94=80=E6=8C=87=E6=A0=87?= =?UTF-8?q?=E6=B1=87=E6=80=BBBI?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- .idea/sqldialects.xml | 1 + BI/销售业绩/营销指标汇总.sql | 87 +++++++++++++++++++++++ FineReport/销售主题/看板/电商KA驾驶舱.sql | 27 +++---- FineReport/销售主题/看板/首页.sql | 57 +++++++++++++++ 4 files changed, 153 insertions(+), 19 deletions(-) create mode 100644 BI/销售业绩/营销指标汇总.sql diff --git a/.idea/sqldialects.xml b/.idea/sqldialects.xml index 39c9f48..5414ccb 100644 --- a/.idea/sqldialects.xml +++ b/.idea/sqldialects.xml @@ -3,6 +3,7 @@ + diff --git a/BI/销售业绩/营销指标汇总.sql b/BI/销售业绩/营销指标汇总.sql new file mode 100644 index 0000000..7cfa2f7 --- /dev/null +++ b/BI/销售业绩/营销指标汇总.sql @@ -0,0 +1,87 @@ +select + stat_date -- 统计时间 + ,bu_code -- 事业部编码 + ,bu_name -- 事业部名称 + ,region_code -- 大区编码 + ,region_name -- 大区名称 + ,office_code -- 办事处编码 + ,office_name -- 办事处名称 + ,deal_code -- 经销商编码 + ,deal_name -- 经销商名称 + ,pl_name -- 产品线 + ,pi_name -- 品项 + -- ,num -- 数量 + -- ,amt -- 金额 + ,SUM(CASE WHEN indi_type = '消费者红包' THEN amt ELSE 0 END) AS consumer_amt -- 消费者红包金额 + ,SUM(CASE WHEN indi_type = '消费者红包' THEN num ELSE 0 END) AS consumer_num -- 消费者红包数量 + + ,SUM(CASE WHEN indi_type = '出货数' THEN amt ELSE 0 END) AS ship_amt -- 出货金额 + ,SUM(CASE WHEN indi_type = '出货数' THEN num ELSE 0 END) AS ship_num -- 出货数量 + + ,SUM(CASE WHEN indi_type = '卡券分润' THEN amt ELSE 0 END) AS coupons_amt -- 卡券分润金额 + ,SUM(CASE WHEN indi_type = '卡券分润' THEN num ELSE 0 END) AS coupons_num -- 卡券分润数量 + + ,SUM(CASE WHEN indi_type = '酒券分润' THEN amt ELSE 0 END) AS wine_amt -- 酒券分润金额 + ,SUM(CASE WHEN indi_type = '酒券分润' THEN num ELSE 0 END) AS wine_num -- 酒券分润数量 + + ,SUM(CASE WHEN indi_type = '消费者兑奖数' THEN amt ELSE 0 END) AS consumer_prize_amt -- 消费者兑奖金额 + ,SUM(CASE WHEN indi_type = '消费者兑奖数' THEN num ELSE 0 END) AS consumer_prize_num -- 消费者兑奖数量 + + ,SUM(CASE WHEN indi_type = '扫码数' THEN amt ELSE 0 END) AS scan_amt -- 扫码数 + ,SUM(CASE WHEN indi_type = '扫码数' THEN num ELSE 0 END) AS scan_num -- 扫码数 + + ,SUM(CASE WHEN indi_type = '消费者卡券' THEN amt ELSE 0 END) AS consumer_coup_amt -- 消费者卡券 + ,SUM(CASE WHEN indi_type = '消费者卡券' THEN num ELSE 0 END) AS consumer_coup_num -- 消费者卡券 + + ,SUM(CASE WHEN indi_type = '终端销售奖' THEN amt ELSE 0 END) AS terminal_amt -- 终端销售奖 + ,SUM(CASE WHEN indi_type = '终端销售奖' THEN num ELSE 0 END) AS terminal_num -- 终端销售奖 + + ,SUM(CASE WHEN indi_type = '异地扫码数' THEN amt ELSE 0 END) AS remote_amt -- 异地扫码数 + ,SUM(CASE WHEN indi_type = '异地扫码数' THEN num ELSE 0 END) AS remote_num -- 异地扫码数 + + ,SUM(CASE WHEN indi_type = '现金分润' THEN amt ELSE 0 END) AS cash_amt -- 现金分润 + ,SUM(CASE WHEN indi_type = '现金分润' THEN num ELSE 0 END) AS cash_num -- 现金分润 +from dm.v_mak_indicator_day a +-- 订单时间 +WHERE stat_date >= '${CONCATENATE(sStart_date," 00:00:00")}' +AND stat_date <= '${CONCATENATE(sEnd_date," 00:00:00")}' +-- 产品线 +${if(len(sPl_name) == 0,"","and a.pl_name in ('" + sPl_name + "')")} +-- 事业部 +${if(len(sBu) == 0,"","and a.bu_code IN ('"+sBu+"')")} +-- 大区 +${if(len(sRegion) == 0,"","and a.region_code IN ('"+ sRegion+"')")} +-- 办事处 +${if(len(sOffice) == 0,"","and a.office_code IN ('"+ sOffice+"')")} +-- 经销商 +${if(sSub_main == '主经销商',if(len(sDeal) == 0,"","and a.deal_code IN ('"+ sDeal+"')"),if(len(sDeal) == 0,"","and a.src_deal_code IN ('"+ sDeal +"')"))} + +-- 权限控制 + 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 -- 办事处 + + ) + ) +group by +stat_date -- 统计时间 +,bu_code -- 事业部编码 +,bu_name -- 事业部名称 +,region_code -- 大区编码 +,region_name -- 大区名称 +,office_code -- 办事处编码 +,office_name -- 办事处名称 +,deal_code -- 经销商编码 +,deal_name -- 经销商名称 +,pl_name -- 产品线 +,pi_name -- 品项 \ No newline at end of file diff --git a/FineReport/销售主题/看板/电商KA驾驶舱.sql b/FineReport/销售主题/看板/电商KA驾驶舱.sql index b2c46a4..1d4d87e 100644 --- a/FineReport/销售主题/看板/电商KA驾驶舱.sql +++ b/FineReport/销售主题/看板/电商KA驾驶舱.sql @@ -1,6 +1,6 @@ -- ====================================== --- 回款 +-- 回款出货情况指标卡 -- 统计维度: 本月、本季度 -- 统计指标: 保底目标、实际达成、达成率 -- 同比、环比 @@ -20,6 +20,7 @@ WITH base_data AS ( 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 @@ -172,23 +173,8 @@ FROM base_data ; - - - - -- ====================================== --- 发货 --- 统计维度: 本月、本季度 --- 统计指标: 保底目标、实际达成、达成率 --- 同比、环比 --- ====================================== - - - - - --- ====================================== --- 回款情况 +-- 回款情况排名 -- 统计时间维度: 月度、季度 -- 维度: 城市单元+负责人 -- 指标: 保底目标、实际达成、达成比、排名 @@ -211,6 +197,8 @@ WITH base_data AS ( 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 @@ -307,7 +295,7 @@ FROM base_date2 -- ====================================== --- 出货情况 +-- 出货情况排名 -- 统计时间维度: 月度、季度 -- 维度: 城市单元+负责人 -- 指标: 保底目标、实际达成、达成比、排名 @@ -329,6 +317,7 @@ WITH base_data AS ( 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 @@ -419,7 +408,7 @@ SELECT , ship_rate_q , row_number() OVER (ORDER BY ship_rate_q DESC ) AS rate_q_rk FROM base_date2 - +; diff --git a/FineReport/销售主题/看板/首页.sql b/FineReport/销售主题/看板/首页.sql index 5d0d49a..ce9c516 100644 --- a/FineReport/销售主题/看板/首页.sql +++ b/FineReport/销售主题/看板/首页.sql @@ -555,6 +555,63 @@ where ${switch(sPeriod -- ${IF(sPeriod=4,"AND to_char(stat_date,'yyyy-MM-dd') <='"+ sEnd_date +"'","")} +-- ====================================== +-- 经销商库存 +-- ====================================== + + +with base_data AS +( + select + indi_type + ,stat_date + ,sum(amt_bu) AS amt + from dm.v_sal_indicator_bu a + where (indi_type='实物库存'OR indi_type='在途库存'OR indi_type='融资未填仓' + OR indi_type='已填仓未下单'OR indi_type='未下单往来余额' OR indi_type='费用余额' OR indi_type='未发货') + AND EXISTS ( + SELECT + 1 + FROM + dm.dm_bi_user_permisson + WHERE + bi_user = '${fine_username}' -- 替换为fine_username + AND per_model IN ('all','sal') + AND ( + is_all = 1 + OR per_code = a.bu_code + ) + ) + GROUP BY + indi_type,stat_date +) +SELECT +SUM(amt) AS amt -- 库存总量 +,SUM(CASE WHEN indi_type = '在途库存' THEN amt ELSE 0 END) AS onway_amt -- 在途库存 +,SUM(CASE WHEN indi_type = '未发货' THEN amt ELSE 0 END) AS not_ship_amt -- 未发货帐余 +,SUM(CASE WHEN indi_type = '融资未填仓' THEN amt ELSE 0 END) AS not_fill_amt -- 融资未填仓 + +FROM base_data +WHERE 1=1 +-- 年 +${IF(sPeriod=1,"AND to_char(stat_date,'yyyy') ='"+ FORMAT(sStart_date,'yyyy') +"'","")} +${IF(sPeriod=1,"AND to_char(stat_date,'yyyy-MM-dd') <='"+ FORMAT(sStart_date,'yyyy-MM-dd') +"'","")} + +-- 季 + ${IF(sPeriod=2,"AND CONCAT(to_char(stat_date,'yyyy'),EXTRACT(QUARTER FROM stat_date)) ='"+ CONCATENATE(left(sStart_date,4),roundup(month(sStart_date)/3)) +"'","")} + ${IF(sPeriod=2,"AND to_char(stat_date,'yyyy-MM-dd') <= '"+ FORMAT(sStart_date,'yyyy-MM-dd') +"'","")} + +-- ${IF(sPeriod=2,"AND to_char(stat_date,'yyyy-MM-dd') <='"+ sEnd_date +"'","")} +-- 月 + ${IF(sPeriod=3,"AND to_char(stat_date,'yyyy-MM') ='"+ FORMAT(sStart_date,'yyyy-MM') +"'","")} + ${IF(sPeriod=3,"AND to_char(stat_date,'yyyy-MM-dd') <= '"+ FORMAT(sStart_date,'yyyy-MM-dd') +"'","")} + +-- ${IF(sPeriod=3,"AND to_char(stat_date,'yyyy-MM-dd') <='"+ sEnd_date +"'","")} +-- 日 +-- ${IF(sPeriod=4,"AND to_char(stat_date,'yyyy-MM-dd') ='"+ sStart_date +"'","")} +-- ${IF(sPeriod=4,"AND to_char(stat_date,'yyyy-MM-dd') <='"+ sEnd_date +"'","")} + + -- ====================================== -- 财务资金状况 -- ======================================