1723 lines
59 KiB
Plaintext
1723 lines
59 KiB
Plaintext
-- 一、建表
|
|
-----------------------------------
|
|
-- 1 创建自定义(国内)门店销售
|
|
-----------------------------------
|
|
DROP TABLE IF EXISTS audit_bi_pro.custom_offline_sale_return_local;
|
|
CREATE TABLE audit_bi_pro.custom_offline_sale_return_local
|
|
(
|
|
`source_system` String COMMENT '来源系统',
|
|
`sale_date` String COMMENT '销售日期',
|
|
`brand_code` String COMMENT '品牌编码',
|
|
`sale_time` Datetime('Asia/Shanghai') COMMENT '销售时间',
|
|
`store_code` String COMMENT '门店编码',
|
|
`store_name` String COMMENT '门店名称',
|
|
`receipt_no` String COMMENT '小票号',
|
|
`goods_amt` Decimal(18,2) COMMENT '商品金额',
|
|
`barcode` String COMMENT '条码',
|
|
`goods_name` String COMMENT '商品名称',
|
|
`qty` Int64 COMMENT '数量',
|
|
`price` Decimal(18,2) COMMENT '单价',
|
|
`pay_type` String COMMENT '收银方式',
|
|
`source_bill_no` String COMMENT '原单据号',
|
|
`sale_status` String COMMENT '销售状态'
|
|
)ENGINE = ReplicatedMergeTree('/clickhouse/tables/audit_bi_pro/custom_offline_sale_return_local/{shard}',
|
|
'{replica}')
|
|
PARTITION BY toYYYYMM(toDate(sale_date))
|
|
ORDER BY receipt_no
|
|
SETTINGS index_granularity = 8192
|
|
COMMENT '自定义门店销售';
|
|
|
|
-----------------------------------
|
|
-- 2 创建海一家订单号关联关系中间表
|
|
-----------------------------------
|
|
DROP TABLE IF EXISTS audit_bi_pro.custom_offline_receipt_BES_local;
|
|
CREATE TABLE audit_bi_pro.custom_offline_receipt_BES_local(
|
|
receipt_no String COMMENT '现单号',
|
|
source_bill_no String COMMENT '来源订单号',
|
|
lv Int64 COMMENT '关联层级'
|
|
)
|
|
ENGINE = ReplicatedMergeTree('/clickhouse/tables/audit_bi_pro/custom_offline_receipt_BES_local/{shard}',
|
|
'{replica}')
|
|
ORDER BY receipt_no
|
|
SETTINGS index_granularity = 8192
|
|
COMMENT '海一家小票号关联关系';
|
|
|
|
-----------------------------------
|
|
-- 3 创建自定义海外门店销售表
|
|
-----------------------------------
|
|
DROP TABLE IF EXISTS audit_bi_pro.custom_offline_abroad_sale_return_local;
|
|
CREATE TABLE audit_bi_pro.custom_offline_abroad_sale_return_local
|
|
(
|
|
`source_system` String COMMENT '来源系统',
|
|
`sale_date` String COMMENT '销售日期',
|
|
`brand_code` String COMMENT '品牌编码',
|
|
`sale_time` Datetime('Asia/Shanghai') COMMENT '销售时间',
|
|
`store_code` String COMMENT '门店编码',
|
|
`store_name` String COMMENT '门店名称',
|
|
`receipt_no` String COMMENT '小票号',
|
|
`goods_amt` Decimal(18,2) COMMENT '商品金额',
|
|
`barcode` String COMMENT '条码',
|
|
`goods_name` String COMMENT '商品名称',
|
|
`qty` Int64 COMMENT '数量',
|
|
`price` Decimal(18,2) COMMENT '单价',
|
|
`pay_type` String COMMENT '收银方式',
|
|
`source_bill_no` String COMMENT '原单据号',
|
|
`sale_status` String COMMENT '销售状态'
|
|
)ENGINE = ReplicatedMergeTree('/clickhouse/tables/audit_bi_pro/custom_offline_abroad_sale_return_local/{shard}',
|
|
'{replica}')
|
|
PARTITION BY toYYYYMM(toDate(sale_date))
|
|
ORDER BY receipt_no
|
|
SETTINGS index_granularity = 8192
|
|
COMMENT '自定义海外门店销售';
|
|
|
|
-----------------------------------
|
|
-- 4 创建汇率表
|
|
-----------------------------------
|
|
DROP TABLE IF EXISTS audit_bi_pro.custom_exchange_rate_local;
|
|
CREATE TABLE audit_bi_pro.custom_exchange_rate_local
|
|
(
|
|
`rate_date` Date COMMENT '日期',
|
|
`currency` String COMMENT '货币',
|
|
`exchange_rate` Decimal(10,6) COMMENT '兑人名币汇率'
|
|
)
|
|
ENGINE = Log
|
|
COMMENT '汇率表';
|
|
|
|
-----------------------------------
|
|
-- 5 创建自定义门店主数据汇总表
|
|
-----------------------------------
|
|
DROP TABLE IF EXISTS audit_bi_pro.custom_store_info_all_local;
|
|
CREATE TABLE audit_bi_pro.custom_store_info_all_local
|
|
(
|
|
`brand_code` String COMMENT '品牌编码',
|
|
`store_code` String COMMENT '门店编码',
|
|
`store_name` String COMMENT '门店名称',
|
|
`store_nature` String COMMENT '门店性质(描述)',
|
|
`open_date` String COMMENT '开店时间',
|
|
`close_date` String COMMENT '关店时间',
|
|
`country` String COMMENT '国家(描述)',
|
|
`province` String COMMENT '省份(描述)',
|
|
`city` String COMMENT '城市(地级市)(描述)',
|
|
`store_status` String COMMENT '门店状态(描述)',
|
|
`period` String COMMENT '会计期间',
|
|
`source_table` String COMMENT '来源表'
|
|
)ENGINE = ReplicatedMergeTree('/clickhouse/tables/audit_bi_pro/custom_store_info_all_local/{shard}',
|
|
'{replica}')
|
|
ORDER BY store_code
|
|
COMMENT '自定义门店主数据汇总表'
|
|
|
|
-----------------------------------
|
|
-- 6 创建自定义门店性质汇总表
|
|
-----------------------------------
|
|
DROP TABLE IF EXISTS audit_bi_pro.custom_store_nature_all_local;
|
|
CREATE TABLE audit_bi_pro.custom_store_nature_all_local
|
|
(
|
|
`brand_code` String COMMENT '品牌编码',
|
|
`store_code` String COMMENT '门店编码',
|
|
`store_name` String COMMENT '门店名称',
|
|
`store_nature` String COMMENT '门店性质(描述)',
|
|
`open_date` String COMMENT '开店时间',
|
|
`close_date` String COMMENT '关店时间',
|
|
`country` String COMMENT '国家(描述)',
|
|
`province` String COMMENT '省份(描述)',
|
|
`city` String COMMENT '城市(地级市)(描述)',
|
|
`store_status` String COMMENT '门店状态(描述)',
|
|
`year` String COMMENT '年份',
|
|
`source_table` String COMMENT '来源表'
|
|
)ENGINE = ReplicatedMergeTree('/clickhouse/tables/audit_bi_pro/custom_store_nature_all_local/{shard}',
|
|
'{replica}')
|
|
ORDER BY store_code
|
|
COMMENT '自定义门店性质汇总表'
|
|
|
|
|
|
-- 7 创建线下城市表
|
|
DROP TABLE IF EXISTS audit_bi_pro.custom_offline_region_city_local;
|
|
CREATE TABLE audit_bi_pro.custom_offline_region_city_local
|
|
(
|
|
`region` String COMMENT '地区',
|
|
`city` String COMMENT '城市'
|
|
)ENGINE =Log;
|
|
|
|
TRUNCATE TABLE IF EXISTS audit_bi_pro.custom_offline_region_city_local;
|
|
|
|
-- 8 创建SBZ新老系统店铺对应表
|
|
DROP TABLE IF EXISTS audit_bi_pro.custom_offline_sbz_store_old_new;
|
|
CREATE TABLE audit_bi_pro.custom_offline_sbz_store_old_new
|
|
(
|
|
`old_store_code` String COMMENT '老系统店铺编码',
|
|
`old_store_name` String COMMENT '老系统店铺名称',
|
|
`store_code` String COMMENT '店铺编码',
|
|
`store_name` String COMMENT '店铺名称'
|
|
)ENGINE =Log;
|
|
|
|
|
|
-- 9 创建SBZ老系统销售数据表
|
|
DROP TABLE IF EXISTS audit_bi_pro.custom_offline_sbz_old_system;
|
|
CREATE TABLE audit_bi_pro.custom_offline_sbz_old_system
|
|
(
|
|
`source_system` String COMMENT '来源系统',
|
|
`sale_date` String COMMENT '销售日期',
|
|
`brand_code` String COMMENT '品牌编码',
|
|
`sale_time` String COMMENT '销售时间',
|
|
`store_code` String COMMENT '门店编码',
|
|
`store_name` String COMMENT '门店名称',
|
|
`receipt_no` String COMMENT '小票号',
|
|
`goods_amt` Decimal(18,2) COMMENT '商品金额',
|
|
`barcode` String COMMENT '条码',
|
|
`goods_name` String COMMENT '商品名称',
|
|
`qty` Int64 COMMENT '数量',
|
|
`price` Decimal(18,2) COMMENT '单价',
|
|
`pay_type` String COMMENT '收银方式',
|
|
`source_bill_no` String COMMENT '原单据号'
|
|
)ENGINE = ReplicatedMergeTree('/clickhouse/tables/audit_bi_pro/custom_offline_sbz_old_system/{shard}',
|
|
'{replica}')
|
|
PARTITION BY toYYYYMM(toDate(sale_date))
|
|
ORDER BY receipt_no
|
|
SETTINGS index_granularity = 8192
|
|
COMMENT '自定义斯搏兹老系统销售表';
|
|
|
|
|
|
-------------------------------
|
|
-- 10 自定义门店销售结算表
|
|
-------------------------------
|
|
-- 国内
|
|
DROP TABLE IF EXISTS audit_bi_pro.custom_offline_sale_return_settle_local;
|
|
CREATE TABLE audit_bi_pro.custom_offline_sale_return_settle_local
|
|
(
|
|
`source_system` String COMMENT '来源系统',
|
|
`sale_date` String COMMENT '销售日期',
|
|
`brand_code` String COMMENT '品牌编码',
|
|
`sale_time` Datetime('Asia/Shanghai') COMMENT '销售时间',
|
|
`store_code` String COMMENT '门店编码',
|
|
`store_name` String COMMENT '门店名称',
|
|
`receipt_no` String COMMENT '小票号',
|
|
`goods_amt` Decimal(18,2) COMMENT '商品金额',
|
|
`barcode` String COMMENT '条码',
|
|
`goods_name` String COMMENT '商品名称',
|
|
`qty` Int64 COMMENT '数量',
|
|
`price` Decimal(18,2) COMMENT '单价',
|
|
`pay_type` String COMMENT '收银方式',
|
|
`source_bill_no` String COMMENT '原单据号',
|
|
`sale_status` String COMMENT '销售状态',
|
|
`store_nature` String COMMENT '门店性质',
|
|
`settle_ratio` Decimal(18,4)COMMENT '结算比例'
|
|
)ENGINE = ReplicatedMergeTree('/clickhouse/tables/audit_bi_pro/custom_offline_sale_return_settle_local/{shard}',
|
|
'{replica}')
|
|
PARTITION BY toYYYYMM(toDate(sale_date))
|
|
ORDER BY receipt_no
|
|
SETTINGS index_granularity = 8192
|
|
COMMENT '自定义国内门店销售结算表';
|
|
|
|
|
|
--海外
|
|
DROP TABLE IF EXISTS audit_bi_pro.custom_offline_abroad_sale_return_settle_local;
|
|
CREATE TABLE audit_bi_pro.custom_offline_abroad_sale_return_settle_local
|
|
(
|
|
`source_system` String COMMENT '来源系统',
|
|
`sale_date` String COMMENT '销售日期',
|
|
`brand_code` String COMMENT '品牌编码',
|
|
`sale_time` Datetime('Asia/Shanghai') COMMENT '销售时间',
|
|
`store_code` String COMMENT '门店编码',
|
|
`store_name` String COMMENT '门店名称',
|
|
`receipt_no` String COMMENT '小票号',
|
|
`goods_amt` Decimal(18,2) COMMENT '商品金额',
|
|
`barcode` String COMMENT '条码',
|
|
`goods_name` String COMMENT '商品名称',
|
|
`qty` Int64 COMMENT '数量',
|
|
`price` Decimal(18,2) COMMENT '单价',
|
|
`pay_type` String COMMENT '收银方式',
|
|
`source_bill_no` String COMMENT '原单据号',
|
|
`sale_status` String COMMENT '销售状态',
|
|
`store_nature` String COMMENT '门店性质',
|
|
`settle_ratio` Decimal(18,4)COMMENT '结算比例'
|
|
)ENGINE = ReplicatedMergeTree('/clickhouse/tables/audit_bi_pro/custom_offline_abroad_sale_return_settle_local/{shard}',
|
|
'{replica}')
|
|
PARTITION BY toYYYYMM(toDate(sale_date))
|
|
ORDER BY receipt_no
|
|
SETTINGS index_granularity = 8192
|
|
COMMENT '自定义海外门店销售结算表';
|
|
|
|
|
|
-----------------------------------
|
|
-- 创建结算比例表
|
|
-----------------------------------
|
|
DROP TABLE IF EXISTS audit_bi_pro.custom_settle_ratio_local;
|
|
CREATE TABLE audit_bi_pro.custom_settle_ratio_local
|
|
(
|
|
`settle_year` String COMMENT '年份',
|
|
`store_nature` String COMMENT '门店性质',
|
|
`settle_ratio` Decimal(18,4) COMMENT '结算比例'
|
|
)
|
|
ENGINE = Log
|
|
COMMENT '结算比例表';
|
|
|
|
-- 二、插入数据
|
|
-----------------------------------
|
|
-- 1 插入国内数据
|
|
-- 1.1 插入非海一家、非男生女生销售、退款数据
|
|
-- 2022-2023
|
|
-----------------------------------
|
|
TRUNCATE TABLE IF EXISTS audit_bi_pro.custom_offline_sale_return_local;
|
|
INSERT INTO audit_bi_pro.custom_offline_sale_return_local
|
|
WITH sale_status AS (
|
|
SELECT
|
|
store_code,
|
|
receipt_no,
|
|
CASE
|
|
-- 金额大于0
|
|
WHEN SUM(goods_amt) > 0 AND MIN(qty) >= 0 THEN '销售'
|
|
WHEN SUM(goods_amt) > 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货销售'
|
|
-- 金额小于0
|
|
WHEN SUM(goods_amt) < 0 AND MAX(qty) <= 0 THEN '退款'
|
|
WHEN SUM(goods_amt) < 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货'
|
|
-- 金额等于0
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货或门店调整'
|
|
WHEN SUM(goods_amt) = 0 AND MIN(qty) > 0 THEN '单赠品销售'
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) < 0 THEN '单赠品退款'
|
|
WHEN SUM(goods_amt) = 0 AND MIN(qty) >= 0 THEN '优惠销售'
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) <= 0 THEN '优惠退款'
|
|
ELSE '其他'
|
|
END AS status
|
|
FROM
|
|
dwd_trade_hkaudit_shop_receipt_mt dthsrm
|
|
WHERE
|
|
toDateTime(sale_time,'Asia/Shanghai') >= '2022-01-01 00:00:00'
|
|
AND toDateTime(sale_time,'Asia/Shanghai') < '2024-01-01 00:00:00'
|
|
AND brand_code NOT IN ('BES','NCL')
|
|
AND barcode NOT IN ('3303000001','3303000002','3303000003','3303000004','3303000007','3303000008','3303000009','3303000010','3303000011',
|
|
'3303000012','3303004000000','3303004000001','3303004000002','1303000154','1303000085','1303000083','1303000084','1303000156')
|
|
GROUP BY store_code,receipt_no
|
|
HAVING status IN('销售','单赠品销售','优惠销售','退款','单赠品退款','优惠退款'))
|
|
SELECT
|
|
a.source_system,
|
|
a.sale_date,
|
|
a.brand_code,
|
|
a.saletime,
|
|
a.store_code,
|
|
a.store_name,
|
|
CASE
|
|
WHEN b.status = '销售' THEN a.receipt_no
|
|
WHEN b.status = '退款' AND a.source_bill_no <> '' THEN a.source_bill_no
|
|
ELSE a.receipt_no
|
|
END AS receipt_no,
|
|
a.goods_amt,
|
|
a.barcode,
|
|
a.goods_name,
|
|
a.qty,
|
|
a.price,
|
|
a.pay_type,
|
|
a.source_bill_no,
|
|
b.status
|
|
FROM(
|
|
SELECT
|
|
*,
|
|
toDateTime(sale_time,'Asia/Shanghai') AS saletime
|
|
FROM
|
|
dwd_trade_hkaudit_shop_receipt_mt dthsrm
|
|
WHERE CONCAT(store_code,receipt_no) IN (SELECT CONCAT(store_code,receipt_no) FROM sale_status)
|
|
AND barcode NOT IN ('3303000001','3303000002','3303000003','3303000004','3303000007','3303000008','3303000009','3303000010','3303000011',
|
|
'3303000012','3303004000000','3303004000001','3303004000002','1303000154','1303000085','1303000083','1303000084','1303000156')
|
|
) a
|
|
LEFT JOIN(
|
|
SELECT
|
|
store_code,
|
|
CASE
|
|
WHEN status IN('销售','单赠品销售','优惠销售') THEN '销售'
|
|
WHEN status IN('退款','单赠品退款','优惠退款') THEN '退款'
|
|
END AS status,
|
|
receipt_no
|
|
FROM sale_status
|
|
) b
|
|
ON a.store_code = b.store_code AND a.receipt_no = b.receipt_no;
|
|
|
|
-----------------------------------
|
|
-- 1 插入国内数据
|
|
-- 1.1 插入非海一家、非男生女生销售、退款数据
|
|
-- 2024-2025
|
|
-----------------------------------
|
|
TRUNCATE TABLE IF EXISTS audit_bi_pro.custom_offline_sale_return_local;
|
|
INSERT INTO audit_bi_pro.custom_offline_sale_return_local
|
|
WITH sale_status AS (
|
|
SELECT
|
|
store_code,
|
|
receipt_no,
|
|
CASE
|
|
-- 金额大于0
|
|
WHEN SUM(goods_amt) > 0 AND MIN(qty) >= 0 THEN '销售'
|
|
WHEN SUM(goods_amt) > 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货销售'
|
|
-- 金额小于0
|
|
WHEN SUM(goods_amt) < 0 AND MAX(qty) <= 0 THEN '退款'
|
|
WHEN SUM(goods_amt) < 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货'
|
|
-- 金额等于0
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货或门店调整'
|
|
WHEN SUM(goods_amt) = 0 AND MIN(qty) > 0 THEN '单赠品销售'
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) < 0 THEN '单赠品退款'
|
|
WHEN SUM(goods_amt) = 0 AND MIN(qty) >= 0 THEN '优惠销售'
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) <= 0 THEN '优惠退款'
|
|
ELSE '其他'
|
|
END AS status
|
|
FROM
|
|
dwd_trade_hkaudit_shop_receipt_mt dthsrm
|
|
WHERE
|
|
toDateTime(sale_time,'Asia/Shanghai') >= '2024-01-01 00:00:00'
|
|
AND toDateTime(sale_time,'Asia/Shanghai') < '2025-07-01 00:00:00'
|
|
AND brand_code NOT IN ('BES','NCL')
|
|
AND barcode NOT IN ('3303000001','3303000002','3303000003','3303000004','3303000007','3303000008','3303000009','3303000010','3303000011',
|
|
'3303000012','3303004000000','3303004000001','3303004000002','1303000154','1303000085','1303000083','1303000084','1303000156')
|
|
GROUP BY store_code,receipt_no
|
|
HAVING status IN('销售','单赠品销售','优惠销售','退款','单赠品退款','优惠退款'))
|
|
SELECT
|
|
a.source_system,
|
|
a.sale_date,
|
|
a.brand_code,
|
|
a.saletime,
|
|
a.store_code,
|
|
a.store_name,
|
|
CASE
|
|
WHEN b.status = '销售' THEN a.receipt_no
|
|
WHEN b.status = '退款' AND a.source_bill_no <> '' THEN a.source_bill_no
|
|
ELSE a.receipt_no
|
|
END AS receipt_no,
|
|
a.goods_amt,
|
|
a.barcode,
|
|
a.goods_name,
|
|
a.qty,
|
|
a.price,
|
|
a.pay_type,
|
|
a.source_bill_no,
|
|
b.status
|
|
FROM(
|
|
SELECT
|
|
*,
|
|
toDateTime(sale_time,'Asia/Shanghai') AS saletime
|
|
FROM
|
|
dwd_trade_hkaudit_shop_receipt_mt dthsrm
|
|
WHERE CONCAT(store_code,receipt_no) IN (SELECT CONCAT(store_code,receipt_no) FROM sale_status)
|
|
AND barcode NOT IN ('3303000001','3303000002','3303000003','3303000004','3303000007','3303000008','3303000009','3303000010','3303000011',
|
|
'3303000012','3303004000000','3303004000001','3303004000002','1303000154','1303000085','1303000083','1303000084','1303000156')
|
|
) a
|
|
LEFT JOIN(
|
|
SELECT
|
|
store_code,
|
|
CASE
|
|
WHEN status IN('销售','单赠品销售','优惠销售') THEN '销售'
|
|
WHEN status IN('退款','单赠品退款','优惠退款') THEN '退款'
|
|
END AS status,
|
|
receipt_no
|
|
FROM sale_status
|
|
) b
|
|
ON a.store_code = b.store_code AND a.receipt_no = b.receipt_no;
|
|
|
|
-----------------------------------
|
|
-- 1 插入国内数据
|
|
-- 1.2 插入非海一家, 非男生女生换货数据
|
|
-- 2022-2023
|
|
-----------------------------------
|
|
INSERT INTO audit_bi_pro.custom_offline_sale_return_local
|
|
WITH sale_status AS (
|
|
SELECT
|
|
store_code,
|
|
receipt_no,
|
|
CASE
|
|
-- 金额大于0
|
|
WHEN SUM(goods_amt) > 0 AND MIN(qty) >= 0 THEN '销售'
|
|
WHEN SUM(goods_amt) > 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货销售'
|
|
-- 金额小于0
|
|
WHEN SUM(goods_amt) < 0 AND MAX(qty) <= 0 THEN '退款'
|
|
WHEN SUM(goods_amt) < 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货'
|
|
-- 金额等于0
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货或门店调整'
|
|
WHEN SUM(goods_amt) = 0 AND MIN(qty) > 0 THEN '单赠品销售'
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) < 0 THEN '单赠品退款'
|
|
WHEN SUM(goods_amt) = 0 AND MIN(qty) >= 0 THEN '优惠销售'
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) <= 0 THEN '优惠退款'
|
|
ELSE '其他'
|
|
END AS status
|
|
FROM
|
|
dwd_trade_hkaudit_shop_receipt_mt dthsrm
|
|
WHERE
|
|
toDateTime(sale_time,'Asia/Shanghai') >= '2022-01-01 00:00:00'
|
|
AND toDateTime(sale_time,'Asia/Shanghai') < '2024-01-01 00:00:00'
|
|
AND brand_code NOT IN ('BES','NCL')
|
|
AND barcode NOT IN ('3303000001','3303000002','3303000003','3303000004','3303000007','3303000008','3303000009','3303000010','3303000011',
|
|
'3303000012','3303004000000','3303004000001','3303004000002','1303000154','1303000085','1303000083','1303000084','1303000156')
|
|
GROUP BY store_code,receipt_no
|
|
HAVING status IN('换货销售','换货'))
|
|
SELECT
|
|
a.source_system,
|
|
a.sale_date,
|
|
a.brand_code,
|
|
a.saletime,
|
|
a.store_code,
|
|
a.store_name,
|
|
CASE
|
|
WHEN (a.qty > 0 OR (a.qty = 0 AND a.goods_amt <=0)) AND a.source_bill_no <> '' THEN a.source_bill_no
|
|
WHEN ((a.qty < 0 AND a.goods_amt <=0) OR (a.qty = 0 and a.goods_amt > 0)) AND a.source_bill_no <> '' THEN a.source_bill_no
|
|
ELSE a.receipt_no
|
|
END AS receipt_no,
|
|
a.goods_amt,
|
|
a.barcode,
|
|
a.goods_name,
|
|
a.qty,
|
|
a.price,
|
|
a.pay_type,
|
|
a.source_bill_no,
|
|
CASE
|
|
WHEN a.qty > 0 OR (a.qty = 0 AND a.goods_amt <=0) THEN '销售'
|
|
WHEN (a.qty < 0 AND a.goods_amt <=0) OR (a.qty = 0 AND a.goods_amt > 0) THEN '退款'
|
|
END AS status
|
|
FROM(
|
|
SELECT
|
|
*,
|
|
toDateTime(sale_time,'Asia/Shanghai') AS saletime
|
|
FROM
|
|
dwd_trade_hkaudit_shop_receipt_mt dthsrm
|
|
WHERE CONCAT(store_code,receipt_no) IN (SELECT CONCAT(store_code,receipt_no) FROM sale_status)
|
|
AND barcode NOT IN ('3303000001','3303000002','3303000003','3303000004','3303000007','3303000008','3303000009','3303000010','3303000011',
|
|
'3303000012','3303004000000','3303004000001','3303004000002','1303000154','1303000085','1303000083','1303000084','1303000156')
|
|
) a
|
|
LEFT JOIN(
|
|
SELECT
|
|
store_code,
|
|
status,
|
|
receipt_no
|
|
FROM sale_status
|
|
) b
|
|
ON a.store_code = b.store_code AND a.receipt_no = b.receipt_no;
|
|
|
|
-----------------------------------
|
|
-- 1 插入国内数据
|
|
-- 1.2 插入非海一家, 非男生女生换货数据
|
|
-- 2024-2025
|
|
-----------------------------------
|
|
INSERT INTO audit_bi_pro.custom_offline_sale_return_local
|
|
WITH sale_status AS (
|
|
SELECT
|
|
store_code,
|
|
receipt_no,
|
|
CASE
|
|
-- 金额大于0
|
|
WHEN SUM(goods_amt) > 0 AND MIN(qty) >= 0 THEN '销售'
|
|
WHEN SUM(goods_amt) > 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货销售'
|
|
-- 金额小于0
|
|
WHEN SUM(goods_amt) < 0 AND MAX(qty) <= 0 THEN '退款'
|
|
WHEN SUM(goods_amt) < 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货'
|
|
-- 金额等于0
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货或门店调整'
|
|
WHEN SUM(goods_amt) = 0 AND MIN(qty) > 0 THEN '单赠品销售'
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) < 0 THEN '单赠品退款'
|
|
WHEN SUM(goods_amt) = 0 AND MIN(qty) >= 0 THEN '优惠销售'
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) <= 0 THEN '优惠退款'
|
|
ELSE '其他'
|
|
END AS status
|
|
FROM
|
|
dwd_trade_hkaudit_shop_receipt_mt dthsrm
|
|
WHERE
|
|
toDateTime(sale_time,'Asia/Shanghai') >= '2024-01-01 00:00:00'
|
|
AND toDateTime(sale_time,'Asia/Shanghai') < '2025-07-01 00:00:00'
|
|
AND brand_code NOT IN ('BES','NCL')
|
|
AND barcode NOT IN ('3303000001','3303000002','3303000003','3303000004','3303000007','3303000008','3303000009','3303000010','3303000011',
|
|
'3303000012','3303004000000','3303004000001','3303004000002','1303000154','1303000085','1303000083','1303000084','1303000156')
|
|
GROUP BY store_code,receipt_no
|
|
HAVING status IN('换货销售','换货'))
|
|
SELECT
|
|
a.source_system,
|
|
a.sale_date,
|
|
a.brand_code,
|
|
a.saletime,
|
|
a.store_code,
|
|
a.store_name,
|
|
CASE
|
|
WHEN (a.qty > 0 OR (a.qty = 0 AND a.goods_amt <=0)) AND a.source_bill_no <> '' THEN a.source_bill_no
|
|
WHEN ((a.qty < 0 AND a.goods_amt <=0) OR (a.qty = 0 and a.goods_amt > 0)) AND a.source_bill_no <> '' THEN a.source_bill_no
|
|
ELSE a.receipt_no
|
|
END AS receipt_no,
|
|
a.goods_amt,
|
|
a.barcode,
|
|
a.goods_name,
|
|
a.qty,
|
|
a.price,
|
|
a.pay_type,
|
|
a.source_bill_no,
|
|
CASE
|
|
WHEN a.qty > 0 OR (a.qty = 0 AND a.goods_amt <=0) THEN '销售'
|
|
WHEN (a.qty < 0 AND a.goods_amt <=0) OR (a.qty = 0 AND a.goods_amt > 0) THEN '退款'
|
|
END AS status
|
|
FROM(
|
|
SELECT
|
|
*,
|
|
toDateTime(sale_time,'Asia/Shanghai') AS saletime
|
|
FROM
|
|
dwd_trade_hkaudit_shop_receipt_mt dthsrm
|
|
WHERE CONCAT(store_code,receipt_no) IN (SELECT CONCAT(store_code,receipt_no) FROM sale_status)
|
|
AND barcode NOT IN ('3303000001','3303000002','3303000003','3303000004','3303000007','3303000008','3303000009','3303000010','3303000011',
|
|
'3303000012','3303004000000','3303004000001','3303004000002','1303000154','1303000085','1303000083','1303000084','1303000156')
|
|
) a
|
|
LEFT JOIN(
|
|
SELECT
|
|
store_code,
|
|
status,
|
|
receipt_no
|
|
FROM sale_status
|
|
) b
|
|
ON a.store_code = b.store_code AND a.receipt_no = b.receipt_no;
|
|
|
|
-----------------------------------
|
|
-- 1 插入国内数据
|
|
-- 1.3 插入海一家关联关系表数据
|
|
-----------------------------------
|
|
TRUNCATE TABLE IF EXISTS audit_bi_pro.custom_offline_receipt_BES_local;
|
|
INSERT INTO audit_bi_pro.custom_offline_receipt_BES_local
|
|
WITH order_chain AS (
|
|
SELECT
|
|
DISTINCT receipt_no,
|
|
source_bill_no
|
|
FROM
|
|
dwd_trade_hkaudit_shop_receipt_mt
|
|
WHERE brand_code = 'BES'
|
|
)
|
|
SELECT
|
|
l0.receipt_no as receipt_no,
|
|
multiIf(
|
|
l7.receipt_no <>'',l7.receipt_no,
|
|
l6.receipt_no <>'',l6.receipt_no,
|
|
l5.receipt_no <>'',l5.receipt_no,
|
|
l4.receipt_no <>'',l4.receipt_no,
|
|
l3.receipt_no <>'',l3.receipt_no, -- 第三级的原始单号
|
|
l2.receipt_no <>'',l2.receipt_no, -- 第二级的原始单号
|
|
l1.receipt_no <>'',l1.receipt_no, -- 第一级的原始单号
|
|
l0.receipt_no -- 自己就是原始单号
|
|
) as source_bill_no,
|
|
CASE
|
|
when l7.receipt_no <>'' then 7
|
|
when l6.receipt_no <>'' then 6
|
|
when l5.receipt_no <>'' then 5
|
|
when l4.receipt_no <>'' then 4
|
|
when l3.receipt_no <>'' then 3
|
|
when l2.receipt_no <>'' then 2
|
|
when l1.receipt_no <>'' then 1
|
|
else 0
|
|
end as lv
|
|
FROM
|
|
order_chain l0
|
|
LEFT JOIN
|
|
order_chain l1
|
|
ON l1.receipt_no = l0.source_bill_no
|
|
LEFT JOIN
|
|
order_chain l2
|
|
ON l2.receipt_no = l1.source_bill_no
|
|
LEFT JOIN
|
|
order_chain l3
|
|
ON l3.receipt_no = l2.source_bill_no
|
|
LEFT JOIN
|
|
order_chain l4
|
|
ON l4.receipt_no = l3.source_bill_no
|
|
LEFT JOIN
|
|
order_chain l5
|
|
ON l5.receipt_no = l4.source_bill_no
|
|
LEFT JOIN
|
|
order_chain l6
|
|
ON l6.receipt_no = l5.source_bill_no
|
|
LEFT JOIN
|
|
order_chain l7
|
|
ON l7.receipt_no = l6.source_bill_no
|
|
WHERE lv <> 7 AND lv <> 0
|
|
|
|
-----------------------------------
|
|
-- 1 插入国内数据
|
|
-- 1.4 插入海一家销售、退款数据
|
|
-----------------------------------
|
|
TRUNCATE TABLE IF EXISTS audit_bi_pro.custom_offline_sale_return_local;
|
|
INSERT INTO audit_bi_pro.custom_offline_sale_return_local
|
|
WITH sale_status AS (
|
|
SELECT
|
|
store_code,
|
|
receipt_no,
|
|
CASE
|
|
-- 金额大于0
|
|
WHEN SUM(goods_amt) > 0 AND MIN(qty) >= 0 THEN '销售'
|
|
WHEN SUM(goods_amt) > 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货销售'
|
|
-- 金额小于0
|
|
WHEN SUM(goods_amt) < 0 AND MAX(qty) <= 0 THEN '退款'
|
|
WHEN SUM(goods_amt) < 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货'
|
|
-- 金额等于0
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货或门店调整'
|
|
WHEN SUM(goods_amt) = 0 AND MIN(qty) > 0 THEN '单赠品销售'
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) < 0 THEN '单赠品退款'
|
|
WHEN SUM(goods_amt) = 0 AND MIN(qty) >= 0 THEN '优惠销售'
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) <= 0 THEN '优惠退款'
|
|
ELSE '其他'
|
|
END AS status
|
|
FROM
|
|
dwd_trade_hkaudit_shop_receipt_mt dthsrm
|
|
WHERE
|
|
toDateTime(sale_time,'Asia/Shanghai') >= '2022-01-01 00:00:00'
|
|
AND toDateTime(sale_time,'Asia/Shanghai') < '2025-07-01 00:00:00'
|
|
AND brand_code ='BES'
|
|
GROUP BY store_code,receipt_no
|
|
HAVING status IN('销售','单赠品销售','优惠销售','退款','单赠品退款','优惠退款'))
|
|
SELECT
|
|
a.source_system,
|
|
a.sale_date,
|
|
a.brand_code,
|
|
a.saletime,
|
|
a.store_code,
|
|
a.store_name,
|
|
CASE
|
|
WHEN b.status = '销售' THEN a.receipt_no
|
|
WHEN b.status = '退款' AND c.source_bill_no <> '' THEN c.source_bill_no
|
|
ELSE a.receipt_no
|
|
END AS receipt_no,
|
|
a.goods_amt,
|
|
a.barcode,
|
|
a.goods_name,
|
|
a.qty,
|
|
a.price,
|
|
a.pay_type,
|
|
c.source_bill_no,
|
|
b.status
|
|
FROM(
|
|
SELECT
|
|
*,
|
|
toDateTime(sale_time,'Asia/Shanghai') AS saletime
|
|
FROM
|
|
dwd_trade_hkaudit_shop_receipt_mt dthsrm
|
|
WHERE CONCAT(store_code,receipt_no) IN (SELECT CONCAT(store_code,receipt_no) FROM sale_status)
|
|
) a
|
|
LEFT JOIN(
|
|
SELECT
|
|
store_code,
|
|
CASE
|
|
WHEN status IN('销售','单赠品销售','优惠销售') THEN '销售'
|
|
WHEN status IN('退款','单赠品退款','优惠退款') THEN '退款'
|
|
END AS status,
|
|
receipt_no
|
|
FROM sale_status
|
|
) b
|
|
ON a.store_code = b.store_code AND a.receipt_no = b.receipt_no
|
|
LEFT JOIN(
|
|
SELECT
|
|
receipt_no,
|
|
source_bill_no
|
|
FROM custom_offline_receipt_BES_local corbl
|
|
WHERE lv <> 0
|
|
)c
|
|
ON a.receipt_no = c.receipt_no;
|
|
|
|
-----------------------------------
|
|
-- 1 插入国内数据
|
|
-- 1.5 插入海一家换货销售数据
|
|
-----------------------------------
|
|
INSERT INTO audit_bi_pro.custom_offline_sale_return_local
|
|
WITH sale_status AS (
|
|
SELECT
|
|
store_code,
|
|
receipt_no,
|
|
CASE
|
|
-- 金额大于0
|
|
WHEN SUM(goods_amt) > 0 AND MIN(qty) >= 0 THEN '销售'
|
|
WHEN SUM(goods_amt) > 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货销售'
|
|
-- 金额小于0
|
|
WHEN SUM(goods_amt) < 0 AND MAX(qty) <= 0 THEN '退款'
|
|
WHEN SUM(goods_amt) < 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货'
|
|
-- 金额等于0
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货或门店调整'
|
|
WHEN SUM(goods_amt) = 0 AND MIN(qty) > 0 THEN '单赠品销售'
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) < 0 THEN '单赠品退款'
|
|
WHEN SUM(goods_amt) = 0 AND MIN(qty) >= 0 THEN '优惠销售'
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) <= 0 THEN '优惠退款'
|
|
ELSE '其他'
|
|
END AS status
|
|
FROM
|
|
dwd_trade_hkaudit_shop_receipt_mt dthsrm
|
|
WHERE
|
|
toDateTime(sale_time,'Asia/Shanghai') >= '2022-01-01 00:00:00'
|
|
AND toDateTime(sale_time,'Asia/Shanghai') < '2025-07-01 00:00:00'
|
|
AND brand_code ='BES'
|
|
GROUP BY store_code,receipt_no
|
|
HAVING status IN ('换货销售','换货'))
|
|
SELECT
|
|
a.source_system,
|
|
a.sale_date,
|
|
a.brand_code,
|
|
a.saletime,
|
|
a.store_code,
|
|
a.store_name,
|
|
CASE
|
|
WHEN (a.qty > 0 OR (a.qty = 0 AND a.goods_amt <=0)) AND c.source_bill_no <> '' THEN c.source_bill_no
|
|
WHEN ((a.qty < 0 AND a.goods_amt <=0) OR (a.qty = 0 and a.goods_amt > 0)) AND c.source_bill_no <> '' THEN c.source_bill_no
|
|
ELSE a.receipt_no
|
|
END AS receipt_no,
|
|
a.goods_amt,
|
|
a.barcode,
|
|
a.goods_name,
|
|
a.qty,
|
|
a.price,
|
|
a.pay_type,
|
|
c.source_bill_no,
|
|
CASE
|
|
WHEN a.qty > 0 OR (a.qty = 0 AND a.goods_amt <=0) THEN '销售'
|
|
WHEN (a.qty < 0 AND a.goods_amt <=0) OR (a.qty = 0 AND a.goods_amt > 0) THEN '退款'
|
|
END AS status
|
|
FROM(
|
|
SELECT
|
|
*,
|
|
toDateTime(sale_time,'Asia/Shanghai') AS saletime
|
|
FROM
|
|
dwd_trade_hkaudit_shop_receipt_mt dthsrm
|
|
WHERE CONCAT(store_code,receipt_no) IN (SELECT CONCAT(store_code,receipt_no) FROM sale_status)
|
|
) a
|
|
LEFT JOIN(
|
|
SELECT
|
|
store_code,
|
|
status,
|
|
receipt_no
|
|
FROM sale_status
|
|
) b
|
|
ON a.store_code = b.store_code AND a.receipt_no = b.receipt_no
|
|
LEFT JOIN(
|
|
SELECT
|
|
receipt_no,
|
|
source_bill_no
|
|
FROM custom_offline_receipt_BES_local corbl
|
|
WHERE lv <> 0
|
|
)c
|
|
ON a.receipt_no = c.receipt_no;
|
|
|
|
-----------------------------------
|
|
-- 1 插入国内数据
|
|
-- 1.6 插入男生女生销售、退款数据
|
|
-----------------------------------
|
|
TRUNCATE TABLE IF EXISTS audit_bi_pro.custom_offline_sale_return_local;
|
|
|
|
INSERT INTO audit_bi_pro.custom_offline_sale_return_local
|
|
WITH sale_status AS (
|
|
SELECT
|
|
store_code,
|
|
receipt_no,
|
|
CASE
|
|
-- 金额大于0
|
|
WHEN SUM(goods_amt) > 0 AND MIN(qty) >= 0 THEN '销售'
|
|
WHEN SUM(goods_amt) > 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货销售'
|
|
-- 金额小于0
|
|
WHEN SUM(goods_amt) < 0 AND MAX(qty) <= 0 THEN '退款'
|
|
WHEN SUM(goods_amt) < 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货'
|
|
-- 金额等于0
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货或门店调整'
|
|
WHEN SUM(goods_amt) = 0 AND MIN(qty) > 0 THEN '单赠品销售'
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) < 0 THEN '单赠品退款'
|
|
WHEN SUM(goods_amt) = 0 AND MIN(qty) >= 0 THEN '优惠销售'
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) <= 0 THEN '优惠退款'
|
|
ELSE '其他'
|
|
END AS status
|
|
FROM
|
|
dwd_trade_hkaudit_shop_receipt_mt dthsrm
|
|
WHERE
|
|
toDateTime(sale_time,'Asia/Shanghai') >= '2022-01-01 00:00:00'
|
|
AND toDateTime(sale_time,'Asia/Shanghai') < '2025-07-01 00:00:00'
|
|
AND brand_code = 'NCL'
|
|
AND receipt_no NOT IN ('99N1LQ2305060003','99N0YU2304070005','99N1LQ2305100004','99N0YU2304100002')
|
|
OR (receipt_no IN('99N1LQ2305060003','99N0YU2304070005') AND goods_amt >0 AND qty>0)
|
|
OR (receipt_no IN('99N1LQ2305100004','99N0YU2304100002') AND goods_amt <0 AND qty<0)
|
|
GROUP BY store_code,receipt_no
|
|
HAVING status IN('销售','单赠品销售','优惠销售','退款','单赠品退款','优惠退款'))
|
|
SELECT
|
|
a.source_system,
|
|
a.sale_date,
|
|
a.brand_code,
|
|
a.saletime,
|
|
a.store_code,
|
|
a.store_name,
|
|
CASE
|
|
WHEN b.status = '销售' THEN a.receipt_no
|
|
WHEN b.status = '退款' AND a.source_bill_no <> '' THEN a.source_bill_no
|
|
ELSE a.receipt_no
|
|
END AS receipt_no,
|
|
a.goods_amt,
|
|
a.barcode,
|
|
a.goods_name,
|
|
a.qty,
|
|
a.price,
|
|
a.pay_type,
|
|
a.source_bill_no,
|
|
b.status
|
|
FROM(
|
|
SELECT
|
|
*,
|
|
toDateTime(sale_time,'Asia/Shanghai') AS saletime
|
|
FROM
|
|
dwd_trade_hkaudit_shop_receipt_mt dthsrm
|
|
WHERE CONCAT(store_code,receipt_no) IN (SELECT CONCAT(store_code,receipt_no) FROM sale_status)
|
|
AND receipt_no NOT IN ('99N1LQ2305060003','99N0YU2304070005','99N1LQ2305100004','99N0YU2304100002')
|
|
OR (receipt_no IN('99N1LQ2305060003','99N0YU2304070005') AND goods_amt >0 AND qty>0)
|
|
OR (receipt_no IN('99N1LQ2305100004','99N0YU2304100002') AND goods_amt <0 AND qty<0)
|
|
) a
|
|
LEFT JOIN(
|
|
SELECT
|
|
store_code,
|
|
CASE
|
|
WHEN status IN('销售','单赠品销售','优惠销售') THEN '销售'
|
|
WHEN status IN('退款','单赠品退款','优惠退款') THEN '退款'
|
|
END AS status,
|
|
receipt_no
|
|
FROM sale_status
|
|
) b
|
|
ON a.store_code = b.store_code AND a.receipt_no = b.receipt_no;
|
|
|
|
-----------------------------------
|
|
-- 1 插入国内数据
|
|
-- 1.7 插入男生女生换货数据
|
|
-----------------------------------
|
|
INSERT INTO audit_bi_pro.custom_offline_sale_return_local
|
|
WITH sale_status AS (
|
|
SELECT
|
|
store_code,
|
|
receipt_no,
|
|
CASE
|
|
-- 金额大于0
|
|
WHEN SUM(goods_amt) > 0 AND MIN(qty) >= 0 THEN '销售'
|
|
WHEN SUM(goods_amt) > 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货销售'
|
|
-- 金额小于0
|
|
WHEN SUM(goods_amt) < 0 AND MAX(qty) <= 0 THEN '退款'
|
|
WHEN SUM(goods_amt) < 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货'
|
|
-- 金额等于0
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货或门店调整'
|
|
WHEN SUM(goods_amt) = 0 AND MIN(qty) > 0 THEN '单赠品销售'
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) < 0 THEN '单赠品退款'
|
|
WHEN SUM(goods_amt) = 0 AND MIN(qty) >= 0 THEN '优惠销售'
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) <= 0 THEN '优惠退款'
|
|
ELSE '其他'
|
|
END AS status
|
|
FROM
|
|
dwd_trade_hkaudit_shop_receipt_mt dthsrm
|
|
WHERE
|
|
toDateTime(sale_time,'Asia/Shanghai') >= '2022-01-01 00:00:00'
|
|
AND toDateTime(sale_time,'Asia/Shanghai') < '2025-07-01 00:00:00'
|
|
AND brand_code = 'NCL'
|
|
AND receipt_no NOT IN ('99N1LQ2305060003','99N0YU2304070005','99N1LQ2305100004','99N0YU2304100002')
|
|
OR (receipt_no IN('99N1LQ2305060003','99N0YU2304070005') AND goods_amt >0 AND qty>0)
|
|
OR (receipt_no IN('99N1LQ2305100004','99N0YU2304100002') AND goods_amt <0 AND qty<0)
|
|
GROUP BY store_code,receipt_no
|
|
HAVING status IN('换货销售','换货'))
|
|
SELECT
|
|
a.source_system,
|
|
a.sale_date,
|
|
a.brand_code,
|
|
a.saletime,
|
|
a.store_code,
|
|
a.store_name,
|
|
CASE
|
|
WHEN (a.qty > 0 OR (a.qty = 0 AND a.goods_amt <=0)) AND a.source_bill_no <> '' THEN a.source_bill_no
|
|
WHEN ((a.qty < 0 AND a.goods_amt <=0) OR (a.qty = 0 and a.goods_amt > 0)) AND a.source_bill_no <> '' THEN a.source_bill_no
|
|
ELSE a.receipt_no
|
|
END AS receipt_no,
|
|
a.goods_amt,
|
|
a.barcode,
|
|
a.goods_name,
|
|
a.qty,
|
|
a.price,
|
|
a.pay_type,
|
|
a.source_bill_no,
|
|
CASE
|
|
WHEN a.qty > 0 OR (a.qty = 0 AND a.goods_amt <=0) THEN '销售'
|
|
WHEN (a.qty < 0 AND a.goods_amt <=0) OR (a.qty = 0 AND a.goods_amt > 0) THEN '退款'
|
|
END AS status
|
|
FROM(
|
|
SELECT
|
|
*,
|
|
toDateTime(sale_time,'Asia/Shanghai') AS saletime
|
|
FROM
|
|
dwd_trade_hkaudit_shop_receipt_mt dthsrm
|
|
WHERE CONCAT(store_code,receipt_no) IN (SELECT CONCAT(store_code,receipt_no) FROM sale_status)
|
|
) a
|
|
LEFT JOIN(
|
|
SELECT
|
|
store_code,
|
|
status,
|
|
receipt_no
|
|
FROM sale_status
|
|
) b
|
|
ON a.store_code = b.store_code AND a.receipt_no = b.receipt_no;
|
|
|
|
-----------------------------------
|
|
-- 1 插入国内数据
|
|
-- 1.8 替换SBZ老系统店铺数据为新系统店铺数据
|
|
-----------------------------------
|
|
TRUNCATE TABLE IF EXISTS audit_bi_pro.custom_offline_sbz_old_system;
|
|
INSERT INTO audit_bi_pro.custom_offline_sbz_old_system
|
|
SELECT
|
|
a.source_system,
|
|
a.sale_date,
|
|
a.brand_code,
|
|
a.sale_time,
|
|
CASE
|
|
WHEN b.store_code <> '' THEN b.store_code
|
|
WHEN b.store_code = '' THEN a.store_code
|
|
END AS store_code,
|
|
CASE
|
|
WHEN b.store_name <> '' THEN b.store_name
|
|
WHEN b.store_name = '' THEN a.store_name
|
|
END AS store_name,
|
|
a.receipt_no,
|
|
a.goods_amt,
|
|
a.barcode,
|
|
a.goods_name,
|
|
a.qty,
|
|
a.price,
|
|
a.pay_type,
|
|
a.source_bill_no
|
|
FROM (
|
|
SELECT * FROM dwd_trade_hkaudit_shop_receipt_other_mt WHERE brand_code = 'SBZ'
|
|
)a
|
|
LEFT JOIN(
|
|
SELECT * FROM custom_offline_sbz_store_old_new
|
|
)b
|
|
ON a.store_code = b.old_store_code
|
|
|
|
-----------------------------------
|
|
-- 1 插入国内数据
|
|
-- 1.9 插入SBZ老系统数据
|
|
-----------------------------------
|
|
TRUNCATE TABLE IF EXISTS audit_bi_pro.custom_offline_sale_return_local;
|
|
INSERT INTO audit_bi_pro.custom_offline_sale_return_local
|
|
WITH sale_status AS (
|
|
SELECT
|
|
store_code,
|
|
CASE
|
|
WHEN receipt_no LIKE '%-%-%' AND LENGTH(receipt_no) = 25 THEN SUBSTR(receipt_no,1,23)
|
|
WHEN receipt_no LIKE '%-%-%' AND LENGTH(receipt_no) = 26 THEN SUBSTR(receipt_no,1,24)
|
|
WHEN receipt_no NOT LIKE '%-%-%' AND LENGTH(receipt_no) = 11 THEN SUBSTR(receipt_no,1,9)
|
|
WHEN receipt_no NOT LIKE '%-%-%' AND LENGTH(receipt_no) IN (23,24,25) THEN receipt_no
|
|
END AS order_id,
|
|
CASE
|
|
-- RC单算销售
|
|
WHEN order_id LIKE 'RC%' THEN '销售'
|
|
-- 金额大于0
|
|
WHEN sum(goods_amt) > 0 AND MIN(qty) >= 0 THEN '销售'
|
|
WHEN sum(goods_amt) > 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货销售'
|
|
-- 金额小于0
|
|
WHEN sum(goods_amt) < 0 AND MAX(qty) <= 0 THEN '退款'
|
|
WHEN sum(goods_amt) < 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货'
|
|
-- 金额等于0s
|
|
WHEN sum(goods_amt) = 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货或门店调整'
|
|
WHEN sum(goods_amt) = 0 AND MIN(qty) > 0 THEN '单赠品销售'
|
|
WHEN sum(goods_amt) = 0 AND MAX(qty) < 0 THEN '单赠品退款'
|
|
WHEN sum(goods_amt) = 0 AND MIN(qty) >= 0 THEN '优惠销售'
|
|
WHEN sum(goods_amt) = 0 AND MAX(qty) <= 0 THEN '优惠退款'
|
|
ELSE '其他'
|
|
END AS status
|
|
FROM
|
|
custom_offline_sbz_old_system dthsrm
|
|
WHERE
|
|
toDateTime(sale_time,'Asia/Shanghai') >= '2024-05-01 00:00:00'
|
|
AND toDateTime(sale_time,'Asia/Shanghai') < '2025-07-01 00:00:00'
|
|
AND brand_code = 'SBZ'
|
|
GROUP BY store_code,order_id
|
|
HAVING status IN('销售','单赠品销售','优惠销售','退款','单赠品退款','优惠退款'))
|
|
SELECT
|
|
a.source_system,
|
|
a.sale_date,
|
|
a.brand_code,
|
|
a.saletime,
|
|
a.store_code,
|
|
a.store_name,
|
|
CASE
|
|
WHEN b.status = '销售' THEN a.a_receipt_no
|
|
WHEN b.status = '退款' AND a.source_bill_no <> '' THEN a.source_bill_no
|
|
ELSE a.a_receipt_no
|
|
END AS receipt_no,
|
|
a.goods_amt,
|
|
a.barcode,
|
|
a.goods_name,
|
|
a.qty,
|
|
a.price,
|
|
a.pay_type,
|
|
a.source_bill_no,
|
|
b.status
|
|
FROM(
|
|
SELECT
|
|
*,
|
|
CASE
|
|
WHEN receipt_no LIKE '%-%-%' AND LENGTH(receipt_no) = 25 THEN SUBSTR(receipt_no,1,23)
|
|
WHEN receipt_no LIKE '%-%-%' AND LENGTH(receipt_no) = 26 THEN SUBSTR(receipt_no,1,24)
|
|
WHEN receipt_no NOT LIKE '%-%-%' AND LENGTH(receipt_no) = 11 THEN SUBSTR(receipt_no,1,9)
|
|
WHEN receipt_no NOT LIKE '%-%-%' AND LENGTH(receipt_no) IN (23,24,25) THEN receipt_no
|
|
END AS a_receipt_no,
|
|
toDateTime(sale_time,'Asia/Shanghai') AS saletime
|
|
FROM
|
|
custom_offline_sbz_old_system dthsrm
|
|
WHERE CONCAT(store_code,a_receipt_no) IN (SELECT CONCAT(store_code,order_id) FROM sale_status)
|
|
AND toDateTime(sale_time,'Asia/Shanghai') >= '2024-05-01 00:00:00'
|
|
AND toDateTime(sale_time,'Asia/Shanghai') < '2025-07-01 00:00:00'
|
|
) a
|
|
LEFT JOIN(
|
|
SELECT
|
|
store_code,
|
|
CASE
|
|
WHEN status IN('销售','单赠品销售','优惠销售') THEN '销售'
|
|
WHEN status IN('退款','单赠品退款','优惠退款') THEN '退款'
|
|
END AS status,
|
|
order_id
|
|
FROM sale_status
|
|
) b
|
|
ON a.store_code = b.store_code AND a.a_receipt_no = b.order_id;
|
|
-----------------------------------
|
|
-- 1 插入国内数据
|
|
-- 1.10 插入SBZ老系统换货数据
|
|
-----------------------------------
|
|
INSERT INTO audit_bi_pro.custom_offline_sale_return_local
|
|
WITH sale_status AS (
|
|
SELECT
|
|
store_code,
|
|
CASE
|
|
WHEN receipt_no LIKE '%-%-%' AND LENGTH(receipt_no) = 25 THEN SUBSTR(receipt_no,1,23)
|
|
WHEN receipt_no LIKE '%-%-%' AND LENGTH(receipt_no) = 26 THEN SUBSTR(receipt_no,1,24)
|
|
WHEN receipt_no NOT LIKE '%-%-%' AND LENGTH(receipt_no) = 11 THEN SUBSTR(receipt_no,1,9)
|
|
WHEN receipt_no NOT LIKE '%-%-%' AND LENGTH(receipt_no) IN (23,24,25) THEN receipt_no
|
|
END AS order_id,
|
|
CASE
|
|
-- 金额大于0
|
|
WHEN sum(goods_amt) > 0 AND MIN(qty) >= 0 THEN '销售'
|
|
WHEN sum(goods_amt) > 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货销售'
|
|
-- 金额小于0
|
|
WHEN sum(goods_amt) < 0 AND MAX(qty) <= 0 THEN '退款'
|
|
WHEN sum(goods_amt) < 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货'
|
|
-- 金额等于0
|
|
WHEN sum(goods_amt) = 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货或门店调整'
|
|
WHEN sum(goods_amt) = 0 AND MIN(qty) > 0 THEN '单赠品销售'
|
|
WHEN sum(goods_amt) = 0 AND MAX(qty) < 0 THEN '单赠品退款'
|
|
WHEN sum(goods_amt) = 0 AND MIN(qty) >= 0 THEN '优惠销售'
|
|
WHEN sum(goods_amt) = 0 AND MAX(qty) <= 0 THEN '优惠退款'
|
|
ELSE '其他'
|
|
END AS status
|
|
FROM
|
|
custom_offline_sbz_old_system dthsrm
|
|
WHERE
|
|
toDateTime(sale_time,'Asia/Shanghai') >= '2024-05-01 00:00:00'
|
|
AND toDateTime(sale_time,'Asia/Shanghai') < '2025-07-01 00:00:00'
|
|
AND brand_code = 'SBZ'
|
|
GROUP BY store_code,order_id
|
|
HAVING status IN('换货销售','换货'))
|
|
SELECT
|
|
a.source_system,
|
|
a.sale_date,
|
|
a.brand_code,
|
|
a.saletime,
|
|
a.store_code,
|
|
a.store_name,
|
|
CASE
|
|
WHEN (a.qty > 0 OR (a.qty = 0 AND a.goods_amt <=0)) AND a.source_bill_no <> '' THEN a.source_bill_no
|
|
WHEN ((a.qty < 0 AND a.goods_amt <=0) OR (a.qty = 0 and a.goods_amt > 0)) AND a.source_bill_no <> '' THEN a.source_bill_no
|
|
ELSE a.a_receipt_no
|
|
END AS receipt_no,
|
|
a.goods_amt,
|
|
a.barcode,
|
|
a.goods_name,
|
|
a.qty,
|
|
a.price,
|
|
a.pay_type,
|
|
a.source_bill_no,
|
|
CASE
|
|
WHEN a.qty > 0 OR (a.qty = 0 AND a.goods_amt <=0) THEN '销售'
|
|
WHEN (a.qty < 0 AND a.goods_amt <=0) OR (a.qty = 0 AND a.goods_amt > 0) THEN '退款'
|
|
END AS status
|
|
FROM(
|
|
SELECT
|
|
*,
|
|
CASE
|
|
WHEN receipt_no LIKE '%-%-%' AND LENGTH(receipt_no) = 25 THEN SUBSTR(receipt_no,1,23)
|
|
WHEN receipt_no LIKE '%-%-%' AND LENGTH(receipt_no) = 26 THEN SUBSTR(receipt_no,1,24)
|
|
WHEN receipt_no NOT LIKE '%-%-%' AND LENGTH(receipt_no) = 11 THEN SUBSTR(receipt_no,1,9)
|
|
WHEN receipt_no NOT LIKE '%-%-%' AND LENGTH(receipt_no) IN (23,24,25) THEN receipt_no
|
|
END AS a_receipt_no,
|
|
toDateTime(sale_time,'Asia/Shanghai') AS saletime
|
|
FROM
|
|
custom_offline_sbz_old_system dthsrm
|
|
WHERE CONCAT(store_code,a_receipt_no) IN (SELECT CONCAT(store_code,order_id) FROM sale_status)
|
|
AND toDateTime(sale_time,'Asia/Shanghai') >= '2024-05-01 00:00:00'
|
|
AND toDateTime(sale_time,'Asia/Shanghai') < '2025-07-01 00:00:00'
|
|
) a
|
|
LEFT JOIN(
|
|
SELECT
|
|
store_code,
|
|
status,
|
|
order_id
|
|
FROM sale_status
|
|
) b
|
|
ON a.store_code = b.store_code AND a.a_receipt_no = b.order_id;
|
|
-----------------------------------
|
|
-- 2 插入海外数据
|
|
-- 2.1导入海外销售、退款
|
|
-----------------------------------
|
|
TRUNCATE TABLE IF EXISTS audit_bi_pro.custom_offline_abroad_sale_return_local;
|
|
INSERT INTO audit_bi_pro.custom_offline_abroad_sale_return_local
|
|
WITH sale_status AS (
|
|
SELECT
|
|
store_code,
|
|
receipt_no,
|
|
CASE
|
|
-- 金额大于0
|
|
WHEN SUM(goods_amt) > 0 AND MIN(qty) >= 0 THEN '销售'
|
|
WHEN SUM(goods_amt) > 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货销售'
|
|
-- 金额小于0
|
|
WHEN SUM(goods_amt) < 0 AND MAX(qty) <= 0 THEN '退款'
|
|
WHEN SUM(goods_amt) < 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货'
|
|
-- 金额等于0
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货或门店调整'
|
|
WHEN SUM(goods_amt) = 0 AND MIN(qty) > 0 THEN '单赠品销售'
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) < 0 THEN '单赠品退款'
|
|
WHEN SUM(goods_amt) = 0 AND MIN(qty) >= 0 THEN '优惠销售'
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) <= 0 THEN '优惠退款'
|
|
ELSE '其他'
|
|
END AS status
|
|
FROM
|
|
dwd_trade_hkaudit_shop_receipt_other_mt
|
|
WHERE
|
|
toDateTime(sale_time,'Asia/Shanghai') >= '2022-01-01 00:00:00'
|
|
AND toDateTime(sale_time,'Asia/Shanghai') < '2025-07-01 00:00:00'
|
|
AND brand_code <> 'SBZ'
|
|
AND receipt_no NOT IN ('01L082301170039009','01L082301170039012','01L082301160039013',
|
|
'01L082301160039015','02L352501190006299','01L082301160039008','01L082301170039011',
|
|
'01L082301170039016','02L082301160038947','01L352502040009339',
|
|
'02E022207240007125','02E042205220008537','04L522409150063759','02E022505010028060')
|
|
GROUP BY store_code,receipt_no
|
|
HAVING status IN('销售','单赠品销售','优惠销售','退款','单赠品退款','优惠退款'))
|
|
SELECT
|
|
a.source_system,
|
|
a.sale_date,
|
|
a.brand_code,
|
|
a.saletime,
|
|
a.store_code,
|
|
a.n_store_name,
|
|
CASE
|
|
WHEN b.status = '销售' THEN a.receipt_no
|
|
WHEN b.status = '退款' AND a.source_bill_no <> '' THEN a.source_bill_no
|
|
ELSE a.receipt_no
|
|
END AS receipt_no,
|
|
ROUND(a.goods_amt * rate.exchange_rate,2) AS goods_amt,
|
|
a.barcode,
|
|
a.goods_name,
|
|
a.qty,
|
|
a.price,
|
|
a.pay_type,
|
|
a.source_bill_no,
|
|
b.status
|
|
FROM(
|
|
SELECT
|
|
m.*,
|
|
CASE
|
|
WHEN n.store_name <> '' THEN n.store_name
|
|
WHEN n.store_name = '' THEN m.store_name
|
|
END AS n_store_name,
|
|
toDateTime(m.sale_time,'Asia/Shanghai') AS saletime,
|
|
CASE
|
|
WHEN SUBSTR(n_store_name,1,6) = '泰国' THEN 'THB'
|
|
WHEN SUBSTR(n_store_name,1,6) = '马来' THEN 'MYR'
|
|
WHEN SUBSTR(n_store_name,1,6) = '越南' THEN 'VND'
|
|
WHEN SUBSTR(n_store_name,1,6) = '菲律' THEN 'PHP'
|
|
WHEN SUBSTR(n_store_name,1,6) = '新加' THEN 'SGD'
|
|
WHEN SUBSTR(n_store_name,1,6) = '印尼' THEN 'IDR'
|
|
WHEN SUBSTR(n_store_name,1,6) = '肯尼' THEN 'KES'
|
|
END AS currency
|
|
FROM(
|
|
SELECT
|
|
*
|
|
FROM
|
|
dwd_trade_hkaudit_shop_receipt_other_mt
|
|
WHERE
|
|
CONCAT(store_code,receipt_no) IN (SELECT CONCAT(store_code,receipt_no) FROM sale_status)
|
|
AND brand_code <>'SBZ'
|
|
AND receipt_no NOT IN ('01L082301170039009','01L082301170039012','01L082301160039013',
|
|
'01L082301160039015','02L352501190006299','01L082301160039008','01L082301170039011',
|
|
'01L082301170039016','02L082301160038947','01L352502040009339',
|
|
'02E022207240007125','02E042205220008537','04L522409150063759','02E022505010028060')
|
|
) m
|
|
LEFT JOIN (
|
|
SELECT
|
|
store_code,
|
|
store_name
|
|
FROM
|
|
dim_hkaudit_store_other_mt
|
|
) n
|
|
ON m.store_code = n.store_code
|
|
) a
|
|
LEFT JOIN(
|
|
SELECT
|
|
store_code,
|
|
CASE
|
|
WHEN status IN('销售','单赠品销售','优惠销售') THEN '销售'
|
|
WHEN status IN('退款','单赠品退款','优惠退款') THEN '退款'
|
|
END AS status,
|
|
receipt_no
|
|
FROM sale_status
|
|
) b
|
|
ON a.store_code = b.store_code AND a.receipt_no = b.receipt_no
|
|
LEFT JOIN (
|
|
SELECT
|
|
rate_date,
|
|
currency,
|
|
exchange_rate
|
|
FROM
|
|
custom_exchange_rate_local
|
|
) rate ON rate.currency = a.currency AND toYear(rate.rate_date) = toYear(a.saletime) AND toMonth(rate.rate_date) = toMonth(a.saletime);
|
|
|
|
-----------------------------------
|
|
-- 2 插入海外数据
|
|
-- 2.2 插入海外换货数据
|
|
-----------------------------------
|
|
INSERT INTO audit_bi_pro.custom_offline_abroad_sale_return_local
|
|
WITH sale_status AS (
|
|
SELECT
|
|
store_code,
|
|
receipt_no,
|
|
CASE
|
|
-- 金额大于0
|
|
WHEN SUM(goods_amt) > 0 AND MIN(qty) >= 0 THEN '销售'
|
|
WHEN SUM(goods_amt) > 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货销售'
|
|
-- 金额小于0
|
|
WHEN SUM(goods_amt) < 0 AND MAX(qty) <= 0 THEN '退款'
|
|
WHEN SUM(goods_amt) < 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货'
|
|
-- 金额等于0
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) > 0 AND MIN(qty)<0 THEN '换货或门店调整'
|
|
WHEN SUM(goods_amt) = 0 AND MIN(qty) > 0 THEN '单赠品销售'
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) < 0 THEN '单赠品退款'
|
|
WHEN SUM(goods_amt) = 0 AND MIN(qty) >= 0 THEN '优惠销售'
|
|
WHEN SUM(goods_amt) = 0 AND MAX(qty) <= 0 THEN '优惠退款'
|
|
ELSE '其他'
|
|
END AS status
|
|
FROM
|
|
dwd_trade_hkaudit_shop_receipt_other_mt dthsrm
|
|
WHERE
|
|
toDateTime(sale_time,'Asia/Shanghai') >= '2022-01-01 00:00:00'
|
|
AND toDateTime(sale_time,'Asia/Shanghai') < '2025-07-01 00:00:00'
|
|
AND brand_code <> 'SBZ'
|
|
AND receipt_no NOT IN ('01L082301170039009','01L082301170039012','01L082301160039013',
|
|
'01L082301160039015','02L352501190006299','01L082301160039008','01L082301170039011',
|
|
'01L082301170039016','02L082301160038947','01L352502040009339',
|
|
'02E022207240007125','02E042205220008537','04L522409150063759','02E022505010028060')
|
|
GROUP BY store_code,receipt_no
|
|
HAVING status IN ('换货销售','换货'))
|
|
SELECT
|
|
a.source_system,
|
|
a.sale_date,
|
|
a.brand_code,
|
|
a.saletime,
|
|
a.store_code,
|
|
a.n_store_name,
|
|
CASE
|
|
WHEN (a.qty > 0 OR (a.qty = 0 AND a.goods_amt <=0)) AND a.source_bill_no <> '' THEN a.source_bill_no
|
|
WHEN ((a.qty < 0 AND a.goods_amt <=0) OR (a.qty = 0 and a.goods_amt > 0)) AND a.source_bill_no <> '' THEN a.source_bill_no
|
|
ELSE a.receipt_no
|
|
END AS receipt_no,
|
|
ROUND(a.goods_amt * rate.exchange_rate,2) AS goods_amt,
|
|
a.barcode,
|
|
a.goods_name,
|
|
a.qty,
|
|
a.price,
|
|
a.pay_type,
|
|
a.source_bill_no,
|
|
CASE
|
|
WHEN a.qty > 0 OR (a.qty = 0 AND a.goods_amt <=0) THEN '销售'
|
|
WHEN (a.qty < 0 AND a.goods_amt <=0) OR (a.qty = 0 AND a.goods_amt > 0) THEN '退款'
|
|
END AS status
|
|
FROM(
|
|
SELECT
|
|
m.*,
|
|
CASE
|
|
WHEN n.store_name <> '' THEN n.store_name
|
|
WHEN n.store_name = '' THEN m.store_name
|
|
END AS n_store_name,
|
|
toDateTime(m.sale_time,'Asia/Shanghai') AS saletime,
|
|
CASE
|
|
WHEN SUBSTR(n_store_name,1,6) = '泰国' THEN 'THB'
|
|
WHEN SUBSTR(n_store_name,1,6) = '马来' THEN 'MYR'
|
|
WHEN SUBSTR(n_store_name,1,6) = '越南' THEN 'VND'
|
|
WHEN SUBSTR(n_store_name,1,6) = '菲律' THEN 'PHP'
|
|
WHEN SUBSTR(n_store_name,1,6) = '新加' THEN 'SGD'
|
|
WHEN SUBSTR(n_store_name,1,6) = '印尼' THEN 'IDR'
|
|
WHEN SUBSTR(n_store_name,1,6) = '肯尼' THEN 'KES'
|
|
END AS currency
|
|
FROM(
|
|
SELECT
|
|
*
|
|
FROM
|
|
dwd_trade_hkaudit_shop_receipt_other_mt
|
|
WHERE
|
|
CONCAT(store_code,receipt_no) IN (SELECT CONCAT(store_code,receipt_no) FROM sale_status)
|
|
AND brand_code <>'SBZ'
|
|
AND receipt_no NOT IN ('01L082301170039009','01L082301170039012','01L082301160039013',
|
|
'01L082301160039015','02L352501190006299','01L082301160039008','01L082301170039011',
|
|
'01L082301170039016','02L082301160038947','01L352502040009339',
|
|
'02E022207240007125','02E042205220008537','04L522409150063759','02E022505010028060')
|
|
) m
|
|
LEFT JOIN (
|
|
SELECT
|
|
store_code,
|
|
store_name
|
|
FROM
|
|
dim_hkaudit_store_other_mt
|
|
) n
|
|
ON m.store_code = n.store_code
|
|
) a
|
|
LEFT JOIN(
|
|
SELECT
|
|
store_code,
|
|
status,
|
|
receipt_no
|
|
FROM sale_status
|
|
) b
|
|
ON a.store_code = b.store_code AND a.receipt_no = b.receipt_no
|
|
LEFT JOIN (
|
|
SELECT
|
|
rate_date,
|
|
currency,
|
|
exchange_rate
|
|
FROM
|
|
custom_exchange_rate_local
|
|
) rate ON rate.currency = a.currency AND toYear(rate.rate_date) = toYear(a.saletime) AND toMonth(rate.rate_date) = toMonth(a.saletime);
|
|
|
|
|
|
-----------------------------------
|
|
-- 3 插入店铺数据
|
|
-- 3.1 插入店铺主数据表
|
|
-----------------------------------
|
|
TRUNCATE TABLE IF EXISTS audit_bi_pro.custom_store_info_all_local;
|
|
INSERT INTO audit_bi_pro.custom_store_info_all_local
|
|
SELECT
|
|
MIN(brand_code) AS brand_code,
|
|
store_code,
|
|
MIN(store_name) AS store_name,
|
|
'' AS store_nature,
|
|
MIN(open_date) AS open_date,
|
|
MIN(close_date) AS close_date,
|
|
MIN(country) AS country,
|
|
MIN(province) AS province,
|
|
MIN(city) AS city,
|
|
'' AS store_status,
|
|
'' AS period,
|
|
'store' AS source_table
|
|
FROM dim_hkaudit_store_mt
|
|
GROUP BY store_code
|
|
UNION ALL
|
|
SELECT
|
|
brand_code,
|
|
store_code,
|
|
store_name,
|
|
'' AS store_nature,
|
|
open_date,
|
|
close_date,
|
|
country,
|
|
province,
|
|
city,
|
|
'' AS store_status,
|
|
'' AS period,
|
|
'store_other' AS source_table
|
|
FROM dim_hkaudit_store_other_mt
|
|
WHERE store_code <>'B01R'
|
|
UNION ALL
|
|
SELECT
|
|
MIN(brand_code) AS min_brand_code,
|
|
store_code,
|
|
MIN(store_name) AS store_name,
|
|
'' AS store_nature,
|
|
MIN(open_date) AS open_date,
|
|
MIN(close_date) AS close_date,
|
|
MIN(country) AS country,
|
|
MIN(CASE
|
|
WHEN province = '天津' THEN '天津市'
|
|
WHEN province = '上海' THEN '上海市'
|
|
ELSE province
|
|
END) AS province,
|
|
MIN(CASE WHEN city = ' 西安市' THEN '西安市'ELSE city END) AS city,
|
|
'' AS store_status,
|
|
'' AS period,
|
|
'jh_sbz' AS source_table
|
|
FROM dim_hkaudit_jh_sbz_store_mt
|
|
WHERE
|
|
CONCAT(brand_code,store_code) NOT IN ('jxhSW00150','sbzS100001')
|
|
AND store_code NOT IN (
|
|
SELECT
|
|
store_code
|
|
FROM (
|
|
SELECT store_code,MIN(store_name) as name from dim_hkaudit_store_mt dhsm group by store_code
|
|
UNION ALL
|
|
SELECT store_code,MIN(store_name) as name from dim_hkaudit_jh_sbz_store_mt dhjssm group by store_code
|
|
)
|
|
GROUP BY store_code
|
|
HAVING COUNT(DISTINCT name) > 1
|
|
)
|
|
GROUP BY store_code;
|
|
|
|
-- 3.2 插入缺少店铺数据
|
|
INSERT INTO audit_bi_pro.custom_store_info_all_local(store_code,store_name,country,province,city,source_table,brand_code) VALUES
|
|
('S454','分销【唯品代销】的店铺','CN','北京市','北京市','store_other','SBZ'),
|
|
('S1538','分销【荟品仓】的店铺','CN','上海市','上海','store_other','SBZ'),
|
|
('S2440','濮阳盛友体育','CN','河南省','濮阳','store_other','SBZ'),
|
|
('S2368','NEO河北邯郸邯山陵西南大街5号阳光世贸广场店','CN','河北省','邯郸','store_other','SBZ'),
|
|
('S1072','上海虹口吉买盛店','CN','上海市','上海','store_other','SBZ'),
|
|
('S2427','常州京榜折扣店','CN','江苏省','常州','store_other','SBZ'),
|
|
('S3094','贵州浅若衣坊','CN','贵州省','贵阳','store_other','SBZ');
|
|
|
|
-----------------------------------
|
|
-- 3.3 插入门店性质表
|
|
-----------------------------------
|
|
TRUNCATE TABLE IF EXISTS audit_bi_pro.custom_store_nature_all_local;
|
|
INSERT INTO audit_bi_pro.custom_store_nature_all_local
|
|
SELECT
|
|
a.brand_code,
|
|
a.store_code,
|
|
a.store_name,
|
|
b.store_nature,
|
|
a.open_date,
|
|
a.close_date,
|
|
a.country,
|
|
a.province,
|
|
a.city,
|
|
a.store_status,
|
|
b.period,
|
|
a.source_table
|
|
FROM(
|
|
SELECT
|
|
*
|
|
FROM
|
|
custom_store_info_all_local
|
|
WHERE
|
|
source_table = 'store'
|
|
) a
|
|
LEFT JOIN(
|
|
SELECT
|
|
store_code,
|
|
CASE
|
|
WHEN store_code ='K020' THEN '联营店'
|
|
ELSE store_nature
|
|
END AS store_nature,
|
|
SUBSTR(period,1,4) AS period
|
|
FROM
|
|
dim_hkaudit_store_mt dhsm
|
|
) b
|
|
ON a.store_code = b.store_code
|
|
UNION ALL
|
|
SELECT
|
|
a.brand_code,
|
|
a.store_code,
|
|
a.store_name,
|
|
CASE
|
|
WHEN a.store_code ='S454' THEN '联营店'
|
|
WHEN a.store_code ='S1538' THEN '联营店'
|
|
WHEN a.store_code ='S2440' THEN '联营店'
|
|
WHEN a.store_code ='S2368' THEN '联营店'
|
|
WHEN a.store_code ='S1072' THEN '联营店'
|
|
WHEN a.store_code ='S2427' THEN '联营店'
|
|
WHEN a.store_code ='S3094' THEN '联营店'
|
|
ELSE b.store_nature
|
|
END AS store_nature,
|
|
a.open_date,
|
|
a.close_date,
|
|
a.country,
|
|
a.province,
|
|
a.city,
|
|
a.store_status,
|
|
'' AS `year`,
|
|
a.source_table
|
|
FROM(
|
|
SELECT
|
|
*
|
|
FROM
|
|
custom_store_info_all_local
|
|
WHERE
|
|
source_table = 'store_other'
|
|
) a
|
|
LEFT JOIN(
|
|
SELECT
|
|
store_code,
|
|
MIN(store_nature) AS store_nature
|
|
FROM
|
|
dim_hkaudit_store_other_mt dhsom
|
|
GROUP BY
|
|
store_code
|
|
) b
|
|
ON a.store_code = b.store_code
|
|
UNION ALL
|
|
SELECT
|
|
a.brand_code,
|
|
a.store_code,
|
|
a.store_name,
|
|
b.store_nature,
|
|
a.open_date,
|
|
a.close_date,
|
|
a.country,
|
|
a.province,
|
|
a.city,
|
|
a.store_status,
|
|
'' AS `year`,
|
|
a.source_table
|
|
FROM(
|
|
SELECT
|
|
*
|
|
FROM
|
|
custom_store_info_all_local
|
|
WHERE
|
|
source_table = 'jh_sbz'
|
|
) a
|
|
LEFT JOIN(
|
|
SELECT
|
|
store_code,
|
|
MIN(store_nature) AS store_nature
|
|
FROM
|
|
dim_hkaudit_jh_sbz_store_mt dhjssm
|
|
GROUP BY
|
|
store_code
|
|
) b
|
|
ON a.store_code = b.store_code
|
|
|
|
-- 3.4 补充剩余年份及性质到店铺性质表
|
|
见导入截图
|
|
|
|
|
|
---------------------------
|
|
-- 4汇总数据至结算表
|
|
-- 4.1 导入数据到结算比例表
|
|
---------------------------
|
|
见导入截图
|
|
|
|
-----------------------------------
|
|
-- 4.2 插入国内数据
|
|
-----------------------------------
|
|
-- 2022-2023
|
|
TRUNCATE TABLE IF EXISTS audit_bi_pro.custom_offline_sale_return_settle_local;
|
|
|
|
INSERT INTO audit_bi_pro.custom_offline_sale_return_settle_local
|
|
SELECT
|
|
a.*,
|
|
CASE
|
|
WHEN b.store_nature <> '' THEN b.store_nature
|
|
WHEN b.store_nature = '' THEN c.store_nature
|
|
END AS store_nature,
|
|
CASE
|
|
WHEN a.brand_code IN ('SBZ','JXH') THEN 1
|
|
WHEN toYear(a.sale_time)= 2022 AND store_nature = '直营店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 1
|
|
WHEN toYear(a.sale_time)= 2022 AND store_nature = '联营店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 0.8256
|
|
WHEN toYear(a.sale_time)= 2022 AND store_nature = '加盟店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 0.5494
|
|
WHEN toYear(a.sale_time)= 2023 AND store_nature = '直营店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 1
|
|
WHEN toYear(a.sale_time)= 2023 AND store_nature = '联营店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 0.7893
|
|
WHEN toYear(a.sale_time)= 2023 AND store_nature = '加盟店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 0.5621
|
|
WHEN toYear(a.sale_time)= 2024 AND store_nature = '直营店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 1
|
|
WHEN toYear(a.sale_time)= 2024 AND store_nature = '联营店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 0.8041
|
|
WHEN toYear(a.sale_time)= 2024 AND store_nature = '加盟店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 0.5684
|
|
WHEN toYear(a.sale_time)= 2024 AND store_nature = '代理店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 0.6485
|
|
WHEN toYear(a.sale_time)= 2025 AND store_nature = '直营店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 1
|
|
WHEN toYear(a.sale_time)= 2025 AND store_nature = '联营店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 0.7925
|
|
WHEN toYear(a.sale_time)= 2025 AND store_nature = '加盟店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 0.5579
|
|
WHEN toYear(a.sale_time)= 2025 AND store_nature = '代理店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 0.5895
|
|
END AS settle_ratio
|
|
FROM custom_offline_sale_return_local a
|
|
LEFT JOIN(
|
|
SELECT
|
|
store_code,
|
|
store_nature,
|
|
`year` AS period
|
|
FROM
|
|
custom_store_nature_all_local csnal
|
|
WHERE
|
|
source_table = 'store'
|
|
)b
|
|
ON a.store_code = b.store_code AND toString(toYear(a.sale_time)) = b.period
|
|
LEFT JOIN(
|
|
SELECT
|
|
store_code,
|
|
store_nature AS store_nature
|
|
FROM
|
|
custom_store_nature_all_local csnal
|
|
WHERE source_table <> 'store'
|
|
)c
|
|
ON a.store_code = c.store_code
|
|
WHERE a.sale_time >='2022-01-01 00:00:00'
|
|
AND a.sale_time <'2024-01-01 00:00:00';
|
|
|
|
|
|
|
|
-- 2024-2025
|
|
INSERT INTO audit_bi_pro.custom_offline_sale_return_settle_local
|
|
SELECT
|
|
a.*,
|
|
CASE
|
|
WHEN b.store_nature <> '' THEN b.store_nature
|
|
WHEN b.store_nature = '' THEN c.store_nature
|
|
END AS store_nature,
|
|
CASE
|
|
WHEN a.brand_code IN ('SBZ','JXH') THEN 1
|
|
WHEN toYear(a.sale_time)= 2022 AND store_nature = '直营店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 1
|
|
WHEN toYear(a.sale_time)= 2022 AND store_nature = '联营店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 0.8256
|
|
WHEN toYear(a.sale_time)= 2022 AND store_nature = '加盟店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 0.5494
|
|
WHEN toYear(a.sale_time)= 2023 AND store_nature = '直营店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 1
|
|
WHEN toYear(a.sale_time)= 2023 AND store_nature = '联营店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 0.7893
|
|
WHEN toYear(a.sale_time)= 2023 AND store_nature = '加盟店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 0.5621
|
|
WHEN toYear(a.sale_time)= 2024 AND store_nature = '直营店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 1
|
|
WHEN toYear(a.sale_time)= 2024 AND store_nature = '联营店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 0.8041
|
|
WHEN toYear(a.sale_time)= 2024 AND store_nature = '加盟店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 0.5684
|
|
WHEN toYear(a.sale_time)= 2024 AND store_nature = '代理店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 0.6485
|
|
WHEN toYear(a.sale_time)= 2025 AND store_nature = '直营店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 1
|
|
WHEN toYear(a.sale_time)= 2025 AND store_nature = '联营店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 0.7925
|
|
WHEN toYear(a.sale_time)= 2025 AND store_nature = '加盟店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 0.5579
|
|
WHEN toYear(a.sale_time)= 2025 AND store_nature = '代理店' AND a.brand_code NOT IN ('SBZ','JXH') THEN 0.5895
|
|
END AS settle_ratio
|
|
FROM custom_offline_sale_return_local a
|
|
LEFT JOIN(
|
|
SELECT
|
|
store_code,
|
|
store_nature,
|
|
`year` AS period
|
|
FROM
|
|
custom_store_nature_all_local csnal
|
|
WHERE
|
|
source_table = 'store'
|
|
)b
|
|
ON a.store_code = b.store_code AND toString(toYear(a.sale_time)) = b.period
|
|
LEFT JOIN(
|
|
SELECT
|
|
store_code,
|
|
store_nature AS store_nature
|
|
FROM
|
|
custom_store_nature_all_local csnal
|
|
WHERE source_table <> 'store'
|
|
)c
|
|
ON a.store_code = c.store_code
|
|
WHERE a.sale_time >='2024-01-01 00:00:00'
|
|
AND a.sale_time <'2025-07-01 00:00:00';
|
|
|
|
-----------------------------------
|
|
-- 4.3 插入海外数据
|
|
-----------------------------------
|
|
TRUNCATE TABLE IF EXISTS audit_bi_pro.custom_offline_abroad_sale_return_settle_local;
|
|
INSERT INTO audit_bi_pro.custom_offline_abroad_sale_return_settle_local
|
|
SELECT
|
|
a.*,
|
|
c.store_nature,
|
|
CASE
|
|
WHEN toYear(a.sale_time)= 2022 AND store_nature = '直营店' THEN 1
|
|
WHEN toYear(a.sale_time)= 2022 AND store_nature = '联营店' THEN 0.8256
|
|
WHEN toYear(a.sale_time)= 2022 AND store_nature = '加盟店' THEN 0.5494
|
|
WHEN toYear(a.sale_time)= 2023 AND store_nature = '直营店' THEN 1
|
|
WHEN toYear(a.sale_time)= 2023 AND store_nature = '联营店' THEN 0.7893
|
|
WHEN toYear(a.sale_time)= 2023 AND store_nature = '加盟店' THEN 0.5621
|
|
WHEN toYear(a.sale_time)= 2024 AND store_nature = '直营店' THEN 1
|
|
WHEN toYear(a.sale_time)= 2024 AND store_nature = '联营店' THEN 0.8041
|
|
WHEN toYear(a.sale_time)= 2024 AND store_nature = '加盟店' THEN 0.5684
|
|
WHEN toYear(a.sale_time)= 2024 AND store_nature = '代理店' THEN 0.6485
|
|
WHEN toYear(a.sale_time)= 2025 AND store_nature = '直营店' THEN 1
|
|
WHEN toYear(a.sale_time)= 2025 AND store_nature = '联营店' THEN 0.7925
|
|
WHEN toYear(a.sale_time)= 2025 AND store_nature = '加盟店' THEN 0.5579
|
|
WHEN toYear(a.sale_time)= 2025 AND store_nature = '代理店' THEN 0.5895
|
|
END AS settle_ratio
|
|
FROM custom_offline_abroad_sale_return_local a
|
|
LEFT JOIN(
|
|
SELECT
|
|
store_code,
|
|
store_nature AS store_nature
|
|
FROM
|
|
custom_store_nature_all_local csnal
|
|
WHERE source_table <> 'store'
|
|
)c
|
|
ON a.store_code = c.store_code;
|
|
|