From 93213cf1d8e564a8d79495388306a4f8a8a64f30 Mon Sep 17 00:00:00 2001 From: yangkunan Date: Mon, 30 Sep 2024 16:57:39 +0800 Subject: [PATCH] =?UTF-8?q?=E7=BB=B4=E5=BA=A6=E8=A1=A8+=E9=94=80=E5=94=AE?= =?UTF-8?q?=E4=B8=9A=E7=BB=A9=E7=BB=84=E5=90=88=E8=A1=A8=E6=95=B0=E6=8D=AE?= =?UTF-8?q?=E9=9B=86=E4=BC=98=E5=8C=96?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit --- .idea/codeStyles/Project.xml | 7 + .idea/codeStyles/codeStyleConfig.xml | 5 + .idea/sqldialects.xml | 1 + FineReport/明细表/销售业绩组合统计表.sql | 634 +++++++++++++---------- FineReport/维度表/产品维度表.sql | 25 + FineReport/维度表/机构维度表.sql | 21 + FineReport/维度表/经销商维度表.sql | 28 + 7 files changed, 434 insertions(+), 287 deletions(-) create mode 100644 .idea/codeStyles/Project.xml create mode 100644 .idea/codeStyles/codeStyleConfig.xml create mode 100644 FineReport/维度表/产品维度表.sql create mode 100644 FineReport/维度表/机构维度表.sql create mode 100644 FineReport/维度表/经销商维度表.sql diff --git a/.idea/codeStyles/Project.xml b/.idea/codeStyles/Project.xml new file mode 100644 index 0000000..bbb85b4 --- /dev/null +++ b/.idea/codeStyles/Project.xml @@ -0,0 +1,7 @@ + + + + + + \ No newline at end of file diff --git a/.idea/codeStyles/codeStyleConfig.xml b/.idea/codeStyles/codeStyleConfig.xml new file mode 100644 index 0000000..79ee123 --- /dev/null +++ b/.idea/codeStyles/codeStyleConfig.xml @@ -0,0 +1,5 @@ + + + + \ No newline at end of file diff --git a/.idea/sqldialects.xml b/.idea/sqldialects.xml index 62cc017..6a16fe7 100644 --- a/.idea/sqldialects.xml +++ b/.idea/sqldialects.xml @@ -4,6 +4,7 @@ + diff --git a/FineReport/明细表/销售业绩组合统计表.sql b/FineReport/明细表/销售业绩组合统计表.sql index 8bed64d..fbd3ae0 100644 --- a/FineReport/明细表/销售业绩组合统计表.sql +++ b/FineReport/明细表/销售业绩组合统计表.sql @@ -13,300 +13,360 @@ +-- EXTRACT(YEAR FROM order_time) AS order_year -- 订单年度 +-- ,EXTRACT(QUARTER FROM order_time) AS order_quar -- 订单季度 +-- ,EXTRACT(MONTH FROM order_time) AS order_month -- 订单月份 +-- ,TO_CHAR(order_time, 'YYYY-MM-DD') AS order_time -- 订单时间 +-- ,EXTRACT(QUARTER FROM A.signed_date) AS ct_quar -- 合同季度 +-- ,EXTRACT(MONTH FROM A.signed_date) AS ct_month -- 合同月份 +-- ,TO_CHAR(A.signed_date, 'YYYY-MM-DD') AS signed_date -- 合同签订日期 +-- EXTRACT(YEAR FROM bill_date) AS order_year -- 单据年度 +-- ,EXTRACT(QUARTER FROM bill_date) AS order_quar -- 单据季度 +-- ,EXTRACT(MONTH FROM bill_date) AS order_month -- 单据月份 +-- ,TO_CHAR(bill_date, 'YYYY-MM-DD') AS order_time -- 单据时间 +-- EXTRACT(YEAR FROM deli_time) AS order_year -- 发货年度 +-- , EXTRACT(QUARTER FROM deli_time) AS order_quar -- 发货季度 +-- , EXTRACT(MONTH FROM deli_time) AS order_month -- 发货月份 +-- , TO_CHAR(deli_time, 'YYYY-MM-DD') AS order_time -- 发货时间 +-- +-- , CASE +-- WHEN stock_month IN ('01', '02', '03') THEN 1 +-- WHEN stock_month IN ('04', '05', '06') THEN 2 +-- WHEN stock_month IN ('07', '08', '09') THEN 3 +-- WHEN stock_month IN ('10', '11', '12') THEN 4 +-- END AS stock_quar +-- , stock_month AS stock_month +-- , CONCAT(stock_year, '-', stock_month, '-01') AS stock_date +-- +-- +-- 参数 +-- 事业部 sBu +-- 事业部大区 sBuRegion +-- 办事处 sOffice +-- 城市单元 sCityUnit +-- 公司大区 sCompRegion - + -- ${if(len(sCityUnit) == 0,"","and city_unit_code IN ('"+sBu+"')")} +-- 省 sProvince +-- 市 sCity +-- 区 sCounty +-- 产品线 sPl +-- 品项 sPi +-- 产品 sProduct +-- 经销商 sDealName +-- 子主经销商 sDeal +-- 开始时间 sStartDate +-- 结束时间 sEndDate SELECT + T1.bu_name AS bu_name -- 事业部名称 + ,T1.region_name AS region_name -- 大区名称 + ,T1.office_name AS office_name -- 办事处名称 + ,T1.city_unit_name AS city_unit_name-- 城市单元名称 + ,T1.province_name AS province_name -- 省 + ,T1.city_name AS city_name -- 市 + ,T1.pl_name AS pl_name -- 产品线名称 + ,T1.pi_name AS pi_name -- 品项 + ,T1.product_name AS product_name -- 产品名称 + ,T1.deal_name AS deal_name -- 经销商名称 + ,T1.src_deal_name AS src_deal_name -- 子经销商名称 + ,SUM(T1.ct_amt ) AS ct_amt -- 合同金额 + ,SUM(T1.total_amt) AS total_amt -- 订单金额 + ,SUM(T1.clc_amt) AS clc_amt -- 回款金额 + ,SUM(T1.deli_amt) AS deli_amt -- 发货金额 + ,SUM(T1.ship_num) AS ship_num -- 发货件数 + ,SUM(T1.ship_botnum) AS ship_botnum -- 发货瓶数 + ,SUM(T1.real_amt) AS real_amt -- 实物库存 - T1.bu_code AS bu_code -- 事业部编码 - ,T1.bu_name AS bu_name -- 事业部名称 - ,T1.region_code AS region_code -- 大区编码 - ,T1.region_name AS region_name -- 大区名称 - ,T1.office_code AS office_code -- 办事处编码 - ,T1.office_name AS office_name -- 办事处名称 - ,T1.city_unit_code AS city_unit_code -- 城市单元编码 - ,T1.city_unit_name AS city_unit_name -- 城市单元名称 - ,T1.province_name AS province_name -- 省 - ,T1.city_name AS city_name -- 市 - ,T1.pl_name AS pl_name -- 产品线名称 - ,T1.pi_name AS pi_name -- 品项 - ,T1.product_code AS product_code -- 产品编码 - ,T1.product_name AS product_name -- 产品名称 - ,T1.deal_code AS deal_code -- 经销商编码 - ,T1.deal_name AS deal_name -- 经销商名称 - ,T1.src_deal_code AS src_deal_code -- 子经销商编码 - ,T1.src_deal_name AS src_deal_name -- 子经销商名称 - ,T1.total_amt AS total_amt -- 订单金额 - ,T2.ct_amt AS ct_amt -- 合同金额 - ,T2.ship_amt AS ship_amt -- 出货金额 - ,T3.clc_amt AS clc_amt -- 回款金额 - ,T4.ship_num AS ship_num -- 发货件数 - ,T5.real_amt AS real_amt -- 实物库存金额 FROM -( - -- 销售订单(订单金额) - SELECT - EXTRACT(YEAR FROM order_time) AS order_year -- 订单年度 - ,EXTRACT(QUARTER FROM order_time) AS order_quar -- 订单季度 - ,EXTRACT(MONTH FROM order_time) AS order_month -- 订单月份 - ,TO_CHAR(order_time, 'YYYY-MM-DD') AS order_time -- 订单时间 - ,bu_code -- 事业部编码 - ,bu_name -- 事业部名称 - -- todo:事业部大区 - -- todo:公司大区 - ,region_code -- 大区编码 - ,region_name -- 大区名称 - ,office_code -- 办事处编码 - ,office_name -- 办事处名称 - ,city_unit_code -- 城市单元编码 - ,city_unit_name -- 城市单元名称 - ,province_name -- 省 - ,city_name -- 市 - -- ,pl_code -- 产品线 - ,pl_name -- 产品线名称 - ,pi_name -- 品项 - ,product_code -- 产品编码 - ,product_name -- 产品名称 - ,deal_code -- 经销商编码 - ,deal_name -- 经销商名称 - ,src_deal_code -- 子经销商编码 - ,src_deal_name -- 子经销商名称 - ,SUM(COALESCE(d_amt,0)) + SUM(COALESCE(e_amt,0)) + SUM(COALESCE(f_amt,0)) + SUM(COALESCE(fz_amt,0)) + SUM(COALESCE(q_amt,0)) AS total_amt -FROM dm.v_ag_sal_order -GROUP BY order_time, order_time, order_time, order_time, bu_code, bu_name, region_code, region_name, office_code, office_name, city_unit_code, city_unit_name, province_name, city_name, pl_name, pi_name, product_code, product_name, deal_code, deal_name, src_deal_code, src_deal_name -)T1 -LEFT JOIN -( + ( +-- 销售订单(订单金额) + SELECT + bu_name -- 事业部名称 + ,region_name -- 大区名称 + ,office_name -- 办事处名称 + ,city_unit_name -- 城市单元名称 + ,province_name -- 省 + ,city_name -- 市 + ,pl_name -- 产品线名称 + ,pi_name -- 品项 + ,product_name -- 产品名称 + ,deal_name -- 经销商名称 + ,src_deal_name -- 子经销商名称 + ,0 AS ct_amt -- 合同金额 + ,SUM(COALESCE(d_amt,0)) + SUM(COALESCE(e_amt,0)) + SUM(COALESCE(f_amt,0)) + SUM(COALESCE(fz_amt,0)) + SUM(COALESCE(q_amt,0)) AS total_amt -- 订单金额 + ,0 AS clc_amt -- 回款金额 + ,0 AS deli_amt -- 发货金额 + ,0 AS ship_num -- 发货件数 + ,0 AS ship_botnum -- 发货瓶数 + ,0 AS real_amt -- 实物库存 + FROM dm.v_ag_sal_order -- 销售订单视图 + WHERE 1 = 1 + AND TO_CHAR(order_time, 'YYYY-MM-DD') >= '${sStartDate}' + AND TO_CHAR(order_time, 'YYYY-MM-DD') < '${sEndDate}' + -- 事业部 + ${if(len(sBu) == 0,"","and bu_code IN ('"+sBu+"')")} + -- 大区 + ${if(len(sCompRegion) == 0,"","and region_code IN ('"+ sCompRegion+"')")} + -- 办事处 + ${if(len(sOffice) == 0,"","and office_code IN ('"+ sOffice+"')")} + -- 城市单元 + ${if(len(sCityUnit) == 0,"","and city_unit_code IN ('"+ sCityUnit+"')")} + -- 省 + ${if(len(sProvince) == 0,"","and province_name IN ('"+ sProvince+"')")} + -- 市 + ${if(len(sCity) == 0,"","and city_name IN ('"+ sCity+"')")} + -- 产品线 + ${if(len(sPl) == 0,"","and pl_name IN ('"+ sPl+"')")} + -- 品项 + ${if(len(sPi) == 0,"","and pi_name IN ('"+ sPi+"')")} + -- 子主经销商 + ${if(sDeal == 1,if(len(sDealName) == 0,"","and deal_code IN ('"+ sDealName+"')"),if(len(sDealName) == 0,"","and src_deal_code IN ('"+ sDealName +"')"))} + GROUP BY + bu_name -- 事业部名称 + ,region_name -- 大区名称 + ,office_name -- 办事处名称 + ,city_unit_name -- 城市单元名称 + ,province_name -- 省 + ,city_name -- 市 + ,pl_name -- 产品线名称 + ,pi_name -- 品项 + ,product_name -- 产品名称 + ,deal_name -- 经销商名称 + ,src_deal_name -- 子经销商名称 + UNION ALL -- 合同汇总 - SELECT - A.ct_year AS ct_year -- 合同年度 - ,EXTRACT(QUARTER FROM A.signed_date) AS ct_quar -- 合同季度 - ,EXTRACT(MONTH FROM A.signed_date) AS ct_month -- 合同月份 - ,TO_CHAR(A.signed_date, 'YYYY-MM-DD') AS signed_date -- 合同签订日期 - ,A.bu_code AS bu_code -- 事业部编码 - -- ,A.bu_name AS bu_name -- 事业部名称 - ,A.region_code AS region_code -- 大区编码 - -- ,A.region_name AS region_name -- 大区名称 - ,A.office_code AS office_code -- 办事处编码 - -- ,A.office_name AS office_name -- 办事处名称 - ,A.city_unit_code AS city_unit_code -- 城市单元编码 - -- ,A.city_unit_name AS city_unit_name -- 城市单元名称 - ,A.province_name AS province_name -- 省 - -- ,A.city_name AS city_name -- 市 - -- ,A.deal_province AS deal_province -- 经销区域-省 - -- ,A.deal_city AS deal_city -- 经销区域-市 - --,A.deal_county AS deal_county -- 经销区域-县 - ,A.pl_code AS pl_code -- 产品线 - ,A.pl_name AS pl_name -- 产品线名称 - ,A.pi_name AS pi_name -- 品项 - ,A.product_code AS product_code -- 产品编码 - ,A.product_name AS product_name -- 产品名称 - ,A.deal_code AS deal_code -- 经销商编码 - ,A.deal_name AS deal_name -- 经销商名称 - ,A.src_deal_code AS src_deal_code -- 子经销商编码 - ,A.src_deal_name AS src_deal_name -- 子经销商名称 - ,SUM(A.ct_amt) AS ct_amt -- 合同金额 - ,SUM(COALESCE(B.ship_amt,0)) AS ship_amt -- 出货金额 - FROM - ( - SELECT - ct_code -- 合同编码 - ,ct_amt -- 合同金额 - ,ct_year -- 合同年度 - ,bu_code -- 事业部编码 - ,bu_name -- 事业部名称 - -- todo:事业部大区 - -- todo:公司大区 - ,region_code -- 大区编码 - ,region_name -- 大区名称 - ,office_code -- 办事处编码 - ,office_name -- 办事处名称 - ,city_unit_code -- 城市单元编码 - ,city_unit_name -- 城市单元名称 - ,province_name -- 省 - ,city_name -- 市 - ,deal_province -- 经销区域-省 - ,deal_city -- 经销区域-市 - ,deal_county -- 经销区域-县 - ,pl_code -- 产品线 - ,pl_name -- 产品线名称 - ,pi_name -- 品项 - ,product_code -- 产品编码 - ,product_name -- 产品名称 - ,deal_code -- 经销商编码 - ,deal_name -- 经销商名称 - ,src_deal_code -- 子经销商编码 - ,src_deal_name -- 子经销商名称 - ,signed_date -- 合同签订时间 todo:时间统计口径待确认 - FROM dm.v_ag_sal_contract -- 合同表 产品+合同ID - )A - LEFT JOIN - ( - SELECT - ct_code -- 合同编码 - ,ct_year -- 合同年度 - ,bu_code -- 事业部编码 - ,region_code -- 大区编码 - ,office_code -- 办事处编码 - ,city_unit_code -- 城市单元编码 - ,deal_code -- 经销商编码 - ,src_deal_code -- 子经销商编码 - ,SUM(ship_amt) AS ship_amt -- 出货金额 - FROM dm.v_ag_sal_contract_ship - GROUP BY ct_code , ct_year, bu_code, region_code, office_code, city_unit_code, deal_code, deal_name, src_deal_code, src_deal_name - )B - ON A.ct_code = B.ct_code - AND A.ct_year = B.ct_year - AND A.bu_code = B.bu_code - AND A.region_code = B.region_code - AND A.office_code = B.office_code - AND A.city_unit_code = B.city_unit_code - AND A.deal_code = B.deal_code - AND A.src_deal_code = B.src_deal_code - GROUP BY A.ct_year, A.signed_date, A.signed_date, A.signed_date, A.bu_code, A.bu_name, A.region_code, A.region_name, A.office_code, A.office_name, A.city_unit_code, A.city_unit_name, A.province_name, A.city_name, A.deal_province, A.deal_city, A.deal_county, A.pl_code, A.pl_name, A.pi_name, A.product_code, A.product_name, A.deal_code, A.deal_name, A.src_deal_code, A.src_deal_name -)T2 -ON T1.bu_code = T2.bu_code -AND T1.region_code = T2.region_code -AND T1.office_code = T2.office_code -AND T1.city_unit_code = T2.city_unit_code -AND T1.province_name = T2.province_name -AND T1.pl_name = T2.pl_name -AND T1.pi_name = T2.pi_name -AND T1.product_code = T2.product_code -AND T1.deal_code = T2.deal_code -AND T1.src_deal_code = T2.src_deal_code -LEFT JOIN -(-- 销售回款 - SELECT - EXTRACT(YEAR FROM bill_date) AS order_year -- 单据年度 - ,EXTRACT(QUARTER FROM bill_date) AS order_quar -- 单据季度 - ,EXTRACT(MONTH FROM bill_date) AS order_month -- 单据月份 - ,TO_CHAR(bill_date, 'YYYY-MM-DD') AS order_time -- 单据时间 - ,bu_code -- 事业部编码 - ,bu_name -- 事业部名称 - -- todo:事业部大区 - -- todo:公司大区 - ,region_code -- 大区编码 - ,region_name -- 大区名称 - ,office_code -- 办事处编码 - ,office_name -- 办事处名称 - ,city_unit_code -- 城市单元编码 - ,city_unit_name -- 城市单元名称 - ,province_name -- 省 - ,city_name -- 市 - -- ,pl_code -- 产品线 - ,pl_name -- 产品线名称 - -- ,pi_name -- 品项 - -- ,product_code -- 产品编码 - --- ,product_name -- 产品名称 - ,deal_code -- 经销商编码 - ,deal_name -- 经销商名称 - ,src_deal_code -- 子经销商编码 - ,src_deal_name -- 子经销商名称 - ,SUM(COALESCE(clc_amt,0)) AS clc_amt -- 回款金额 - FROM dm.v_ag_sal_collection -- 销售回款 - GROUP BY bill_date, bill_date, bill_date, bill_date, bu_code, bu_name, region_code, region_name, office_code, office_name, city_unit_code, city_unit_name, province_name, city_name, pl_name, deal_code, deal_name, src_deal_code, src_deal_name -)T3 -ON T1.bu_code = T3.bu_code -AND T1.region_code = T3.region_code -AND T1.office_code = T3.office_code -AND T1.city_unit_code = T3.city_unit_code -AND T1.province_name = T3.province_name -AND T1.pl_name = T3.pl_name --- AND T1.pi_name = T3.pi_name --- AND T1.product_code = T3.product_code -AND T1.deal_code = T3.deal_code -AND T1.src_deal_code = T3.src_deal_code -LEFT JOIN -( + SELECT + bu_name -- 事业部名称 + ,region_name -- 大区名称 + ,office_name -- 办事处名称 + ,city_unit_name -- 城市单元名称 + ,province_name -- 省 + ,city_name -- 市 + ,pl_name -- 产品线名称 + ,pi_name -- 品项 + ,product_name -- 产品名称 + ,deal_name -- 经销商名称 + ,src_deal_name -- 子经销商名称 + ,sum(ct_amt) as ct_amt -- 合同金额 + ,0 AS total_amt -- 订单金额 + ,0 AS clc_amt -- 回款金额 + ,0 AS deli_amt -- 发货金额 + ,0 AS ship_num -- 发货件数 + ,0 AS ship_botnum-- 发货瓶数 + ,0 AS real_amt -- 实物库存 + FROM dm.v_ag_sal_contract -- 合同表 产品+合同ID + WHERE 1 = 1 + AND TO_CHAR(signed_date, 'YYYY-MM-DD') >= '${sStartDate}' + AND TO_CHAR(signed_date, 'YYYY-MM-DD') < '${sEndDate}' + -- 事业部 + ${if(len(sBu) == 0,"","and bu_code IN ('"+sBu+"')")} + -- 大区 + ${if(len(sCompRegion) == 0,"","and region_code IN ('"+ sCompRegion+"')")} + -- 办事处 + ${if(len(sOffice) == 0,"","and office_code IN ('"+ sOffice+"')")} + -- 城市单元 + ${if(len(sCityUnit) == 0,"","and city_unit_code IN ('"+ sCityUnit+"')")} + -- 省 + ${if(len(sProvince) == 0,"","and province_name IN ('"+ sProvince+"')")} + -- 市 + ${if(len(sCity) == 0,"","and city_name IN ('"+ sCity+"')")} + -- 产品线 + ${if(len(sPl) == 0,"","and pl_name IN ('"+ sPl+"')")} + -- 品项 + ${if(len(sPi) == 0,"","and pi_name IN ('"+ sPi+"')")} + -- 子主经销商 + ${if(sDeal == 1,if(len(sDealName) == 0,"","and deal_code IN ('"+ sDealName+"')"),if(len(sDealName) == 0,"","and src_deal_code IN ('"+ sDealName +"')"))} + GROUP BY + bu_name -- 事业部名称 + ,region_name -- 大区名称 + ,office_name -- 办事处名称 + ,city_unit_name -- 城市单元名称 + ,province_name -- 省 + ,city_name -- 市 + ,pl_name -- 产品线名称 + ,pi_name -- 品项 + ,product_name -- 产品名称 + ,deal_name -- 经销商名称 + ,src_deal_name -- 子经销商名称 + UNION ALL + -- 销售回款 + SELECT + bu_name -- 事业部名称 + ,region_name -- 大区名称 + ,office_name -- 办事处名称 + ,city_unit_name -- 城市单元名称 + ,province_name -- 省 + ,city_name -- 市 + ,pl_name -- 产品线名称 + ,'' AS pi_name -- 品项 + ,'' AS product_name -- 产品名称 + ,deal_name -- 经销商名称 + ,src_deal_name -- 子经销商名称 + ,0 AS ct_amt -- 合同金额 + ,0 AS total_amt -- 订单金额 + ,SUM(COALESCE(clc_amt,0)) AS clc_amt -- 回款金额 + ,0 AS deli_amt -- 发货金额 + ,0 AS ship_num -- 发货件数 + ,0 AS ship_botnum-- 发货瓶数 + ,0 AS real_amt -- 实物库存 + FROM dm.v_ag_sal_collection -- 销售回款 + WHERE 1=1 + AND TO_CHAR(bill_date, 'YYYY-MM-DD') >= '${sStartDate}' + AND TO_CHAR(bill_date, 'YYYY-MM-DD') < '${sEndDate}' + -- 事业部 + ${if(len(sBu) == 0,"","and bu_code IN ('"+sBu+"')")} + -- 大区 + ${if(len(sCompRegion) == 0,"","and region_code IN ('"+ sCompRegion+"')")} + -- 办事处 + ${if(len(sOffice) == 0,"","and office_code IN ('"+ sOffice+"')")} + -- 城市单元 + ${if(len(sCityUnit) == 0,"","and city_unit_code IN ('"+ sCityUnit+"')")} + -- 省 + ${if(len(sProvince) == 0,"","and province_name IN ('"+ sProvince+"')")} + -- 市 + ${if(len(sCity) == 0,"","and city_name IN ('"+ sCity+"')")} + -- 产品线 + ${if(len(sPl) == 0,"","and pl_name IN ('"+ sPl+"')")} + -- 子主经销商 + ${if(sDeal == 1,if(len(sDealName) == 0,"","and deal_code IN ('"+ sDealName+"')"),if(len(sDealName) == 0,"","and src_deal_code IN ('"+ sDealName +"')"))} + + GROUP BY + bu_name -- 事业部名称 + ,region_name -- 大区名称 + ,office_name -- 办事处名称 + ,city_unit_name -- 城市单元名称 + ,province_name -- 省 + ,city_name -- 市 + ,pl_name -- 产品线名称 + ,deal_name -- 经销商名称 + ,src_deal_name -- 子经销商名称 + + UNION ALL -- 销售发货 - SELECT EXTRACT(YEAR FROM deli_time) AS order_year -- 发货年度 - , EXTRACT(QUARTER FROM deli_time) AS order_quar -- 发货季度 - , EXTRACT(MONTH FROM deli_time) AS order_month -- 发货月份 - , TO_CHAR(deli_time, 'YYYY-MM-DD') AS order_time -- 发货时间 - , bu_code -- 事业部编码 - , bu_name -- 事业部名称 - -- todo:事业部大区 - -- todo:公司大区 - , region_code -- 大区编码 - , region_name -- 大区名称 - , office_code -- 办事处编码 - , office_name -- 办事处名称 - , city_unit_code -- 城市单元编码 - , city_unit_name -- 城市单元名称 - , province_name -- 省 - , city_name -- 市 - , pl_name -- 产品线名称 - , pi_name -- 品项 - , product_code -- 产品编码 - , product_name -- 产品名称 - , deal_code -- 经销商编码 - , deal_name -- 经销商名称 - , src_deal_code -- 子经销商编码 - , src_deal_name -- 子经销商名称 - , deli_amt -- 发货总金额 - , SUM(deli_num / pack_base_num) AS ship_num-- 发货件数 = 发货数量 / 转化率 - -- todo 发货瓶数 - FROM dm.v_ag_sal_deliver - GROUP BY deli_time, deli_time, deli_time, deli_time, bu_code, bu_name, region_code, region_name, office_code, - office_name, city_unit_code, city_unit_name, province_name, city_name, pl_name, pi_name, product_code, - product_name, deal_code, deal_name, src_deal_code, src_deal_name, deli_amt -)T4 -ON T1.bu_code = T4.bu_code -AND T1.region_code = T4.region_code -AND T1.office_code = T4.office_code -AND T1.city_unit_code = T4.city_unit_code -AND T1.province_name = T4.province_name -AND T1.pl_name = T4.pl_name -AND T1.pi_name = T4.pi_name -AND T1.product_code = T4.product_code -AND T1.deal_code = T4.deal_code -AND T1.src_deal_code = T4.src_deal_code -LEFT JOIN -( --- 实物库存 - SELECT stock_year AS stock_year -- 年度 - , CASE - WHEN stock_month IN ('01', '02', '03') THEN 1 - WHEN stock_month IN ('04', '05', '06') THEN 2 - WHEN stock_month IN ('07', '08', '09') THEN 3 - WHEN stock_month IN ('10', '11', '12') THEN 4 - END AS stock_quar - , stock_month AS stock_month - , CONCAT(stock_year, '-', stock_month, '-01') AS stock_date - , bu_code -- 事业部编码 - , bu_name -- 事业部名称 - -- todo:事业部大区 - -- todo:公司大区 - , region_code -- 大区编码 - , region_name -- 大区名称 - , office_code -- 办事处编码 - , office_name -- 办事处名称 - , city_unit_code -- 城市单元编码 - , city_unit_name -- 城市单元名称 - , province_name -- 省 - , city_name -- 市 - , pl_name -- 产品线名称 - , pi_name -- 品项 - , product_code -- 产品编码 - , product_name -- 产品名称 - , deal_code -- 经销商编码 - , deal_name -- 经销商名称 - , SUM(end_num * price) AS real_amt -- 实物库存金额 - FROM dm.v_ag_sal_deal_stock - GROUP BY stock_year, stock_month, bu_code, bu_name, region_code, region_name, office_code, office_name, - city_unit_code, city_unit_name, province_name, city_name, pl_name, pi_name, product_code, product_name, - deal_code, deal_name -)T5 -ON T1.bu_code = T5.bu_code -AND T1.region_code = T5.region_code -AND T1.office_code = T5.office_code -AND T1.city_unit_code = T5.city_unit_code -AND T1.province_name = T5.province_name -AND T1.pl_name = T5.pl_name -AND T1.pi_name = T5.pi_name -AND T1.product_code = T5.product_code -AND T1.deal_code = T5.deal_code + SELECT + bu_name -- 事业部名称 + ,region_name -- 大区名称 + ,office_name -- 办事处名称 + ,city_unit_name -- 城市单元名称 + ,province_name -- 省 + ,city_name -- 市 + ,pl_name -- 产品线名称 + ,pi_name -- 品项 + ,product_name -- 产品名称 + ,deal_name -- 经销商名称 + ,src_deal_name -- 子经销商名称 + ,0 AS ct_amt -- 合同金额 + ,0 AS total_amt -- 订单金额 + ,0 AS clc_amt -- 回款金额 + ,SUM(deli_amt) AS deli_amt -- 发货金额 + ,SUM(deli_num / pack_base_num) AS ship_num -- 发货件数 + ,0 AS ship_botnum-- 发货瓶数 + ,0 AS real_amt -- 实物库存 + FROM dm.v_ag_sal_deliver + WHERE 1=1 + AND TO_CHAR(deli_time, 'YYYY-MM-DD') >= '${sStartDate}' + AND TO_CHAR(deli_time, 'YYYY-MM-DD') < '${sEndDate}' + -- 事业部 + ${if(len(sBu) == 0,"","and bu_code IN ('"+sBu+"')")} + -- 大区 + ${if(len(sCompRegion) == 0,"","and region_code IN ('"+ sCompRegion+"')")} + -- 办事处 + ${if(len(sOffice) == 0,"","and office_code IN ('"+ sOffice+"')")} + -- 城市单元 + ${if(len(sCityUnit) == 0,"","and city_unit_code IN ('"+ sCityUnit+"')")} + -- 省 + ${if(len(sProvince) == 0,"","and province_name IN ('"+ sProvince+"')")} + -- 市 + ${if(len(sCity) == 0,"","and city_name IN ('"+ sCity+"')")} + -- 产品线 + ${if(len(sPl) == 0,"","and pl_name IN ('"+ sPl+"')")} + -- 品项 + ${if(len(sPi) == 0,"","and pi_name IN ('"+ sPi+"')")} + -- 子主经销商 + ${if(sDeal == 1,if(len(sDealName) == 0,"","and deal_code IN ('"+ sDealName+"')"),if(len(sDealName) == 0,"","and src_deal_code IN ('"+ sDealName +"')"))} + + GROUP BY + bu_name -- 事业部名称 + ,region_name -- 大区名称 + ,office_name -- 办事处名称 + ,city_unit_name -- 城市单元名称 + ,province_name -- 省 + ,city_name -- 市 + ,pl_name -- 产品线名称 + ,pi_name -- 品项 + ,product_name -- 产品名称 + ,deal_name -- 经销商名称 + ,src_deal_name -- 子经销商名称 + UNION ALL + -- 实物库存 + SELECT + bu_name -- 事业部名称 + ,region_name -- 大区名称 + ,office_name -- 办事处名称 + ,city_unit_name -- 城市单元名称 + ,province_name -- 省 + ,city_name -- 市 + ,pl_name -- 产品线名称 + ,pi_name -- 品项 + ,product_name -- 产品名称 + ,deal_name -- 经销商名称 + ,src_deal_name -- 子经销商名称 + ,0 AS ct_amt -- 合同金额 + ,0 AS total_amt -- 订单金额 + ,0 AS clc_amt -- 回款金额 + ,0 AS deli_amt -- 发货金额 + ,0 AS ship_num -- 发货件数 + ,0 AS ship_botnum-- 发货瓶数 + ,SUM(end_num * price) AS real_amt -- 实物库存金额 + FROM dm.v_ag_sal_deal_stock + WHERE 1=1 + AND CONCAT(stock_year, '-', stock_month, '-01') >= '${sStartDate}' + AND CONCAT(stock_year, '-', stock_month, '-01') < '${sEndDate}' + -- 事业部 + ${if(len(sBu) == 0,"","and bu_code IN ('"+sBu+"')")} + -- 大区 + ${if(len(sCompRegion) == 0,"","and region_code IN ('"+ sCompRegion+"')")} + -- 办事处 + ${if(len(sOffice) == 0,"","and office_code IN ('"+ sOffice+"')")} + -- 城市单元 + ${if(len(sCityUnit) == 0,"","and city_unit_code IN ('"+ sCityUnit+"')")} + -- 省 + ${if(len(sProvince) == 0,"","and province_name IN ('"+ sProvince+"')")} + -- 市 + ${if(len(sCity) == 0,"","and city_name IN ('"+ sCity+"')")} + -- 产品线 + ${if(len(sPl) == 0,"","and pl_name IN ('"+ sPl+"')")} + -- 品项 + ${if(len(sPi) == 0,"","and pi_name IN ('"+ sPi+"')")} + -- 子主经销商 + ${if(sDeal == 1,if(len(sDealName) == 0,"","and deal_code IN ('"+ sDealName+"')"),if(len(sDealName) == 0,"","and src_deal_code IN ('"+ sDealName +"')"))} + + GROUP BY + bu_name -- 事业部名称 + ,region_name -- 大区名称 + ,office_name -- 办事处名称 + ,city_unit_name -- 城市单元名称 + ,province_name -- 省 + ,city_name -- 市 + ,pl_name -- 产品线名称 + ,pi_name -- 品项 + ,product_name -- 产品名称 + ,deal_name -- 经销商名称 + ,src_deal_name -- 子经销商名称 + )T1 +GROUP BY + T1.bu_name + ,T1.region_name + ,T1.office_name + ,T1.city_unit_name + ,T1.province_name + ,T1.city_name + ,T1.pl_name + ,T1.pi_name + ,T1.product_name + ,T1.deal_name + ,T1.src_deal_name ; \ No newline at end of file diff --git a/FineReport/维度表/产品维度表.sql b/FineReport/维度表/产品维度表.sql new file mode 100644 index 0000000..e966b6b --- /dev/null +++ b/FineReport/维度表/产品维度表.sql @@ -0,0 +1,25 @@ +-- ====================================== +-- 产品维度表 +-- ====================================== + + +SELECT + product_code --产品编码 + ,product_name --产品名称 + ,pi_code --品项编码 + ,pi_name --品项名称 + ,pl_code --产品线编码 + ,pl_name --产品线名称 + ,price --出厂价 + ,spec --规格 + ,base_unit --基本单位 + ,pack_unit --包装单位 + ,pack_base_num --转换率 + ,pr_code --产品系列编码 + ,pr_name --产品系列名称 + ,bu_code --产品所属事业部编码 + ,aroma_type --香型 + ,alc_degree --酒精度数 + ,price_out --计划外或经销商价 + ,price_in --计划内或运营商价 +FROM dwr.dim_product diff --git a/FineReport/维度表/机构维度表.sql b/FineReport/维度表/机构维度表.sql new file mode 100644 index 0000000..48768cf --- /dev/null +++ b/FineReport/维度表/机构维度表.sql @@ -0,0 +1,21 @@ +-- ====================================== +-- 机构维度表 +-- ====================================== + + +select + dept_code -- 城市单元编码 + ,dept_name -- 城市单元名称 + ,thrd_dept_code -- 办事处编码 + ,thrd_dept_name -- 办事处名称 + ,secd_dept_code -- 大区编码 + ,secd_dept_name -- 大区名称 + ,fist_dept_code -- 事业部编码 + ,fist_dept_name -- 事业部名称 +from dwr.dim_department +where dept_level=4 +and corp_code='0202' +and enabled_status=1 +and fist_dept_code in ('0202/0212','0202/0225','0202/0226','0202/0209','0202/0252') +and thrd_dept_name !~'停用|废' +and secd_dept_name !~'停用|废' \ No newline at end of file diff --git a/FineReport/维度表/经销商维度表.sql b/FineReport/维度表/经销商维度表.sql new file mode 100644 index 0000000..80b1bc3 --- /dev/null +++ b/FineReport/维度表/经销商维度表.sql @@ -0,0 +1,28 @@ +-- ====================================== +-- 经销商维度表 +-- ====================================== +select + a.deal_code AS deal_code -- 经销商编码 + ,b.deal_name AS deal_name -- 经销商名称 + ,a.city_unit_code AS city_unit_code -- 城市单元编码 + ,a.city_unit_name AS city_unit_name -- 城市单元名称 + ,a.office_code AS office_code -- 办事处编码 + ,a.office_name AS office_name -- 办事处名称 + ,a.region_code AS region_code -- 大区编码 + ,a.region_name AS region_name -- 大区名称 + ,a.bu_code AS bu_code -- 事业部编码 + ,a.bu_name AS bu_name -- 事业部名称 + ,b.country_code AS country_code -- 国家编码 + ,b.country_name AS country_name -- 国别 + ,b.province_code AS province_code -- 省级编码 + ,b.province_name AS province_name -- 注册地所在省 + ,b.city_code AS city_code -- 市级编码 + ,b.city_name AS city_name -- 注册地所在市 + ,b.county_code AS county_code -- 县级编码 + ,b.county_name AS county_name -- 注册地所在县 +from dwr.dim_dealer_administer a +left join dwr.dim_dealer b +on a.deal_code=b.deal_code +where a.enabled_status=1 + and a.region_name !~'停用' + and a.office_name !~'停用'