diff --git a/.idea/sqldialects.xml b/.idea/sqldialects.xml index e24bf38..62cc017 100644 --- a/.idea/sqldialects.xml +++ b/.idea/sqldialects.xml @@ -1,7 +1,9 @@ + + diff --git a/FineReport/明细表/销售业绩组合统计表.sql b/FineReport/明细表/销售业绩组合统计表.sql new file mode 100644 index 0000000..8bed64d --- /dev/null +++ b/FineReport/明细表/销售业绩组合统计表.sql @@ -0,0 +1,312 @@ +-- ***************************** +-- 创建人员: 杨坤安 +-- 创建时间: 2024-09-29 +-- 功能描述: 销售业绩组合统计表 +-- ***************************** + +-- 思路: 1. 先按维度汇总,实际上是张汇总表 +-- 2. 按维度去关联,形成一张大表 +-- 3. 根据不同的筛选条件去筛选数据 + +-- 动态维度:年、季、月、日、事业部、事业部大区、办事处、城市单元、公司大区、省、市、区、产品线、品项、产品、主经销商、子经销商 +-- 指标:合同、订单、回款、发货(金额、件数、瓶数)、实物库存、 + + + + + + +SELECT + + 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 + 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 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 +; \ No newline at end of file