From 3570da7c0f73efe1ec7b43894148ce5b4adac500 Mon Sep 17 00:00:00 2001 From: Qiuyi LI Date: Mon, 7 Aug 2023 16:27:36 +0200 Subject: [PATCH] Add SQL backup scripts for existing views --- db/util.sql | 76 +++++++++++++++++++ db/views/api_view.sql | 13 ++++ db/views/calculate_shipping_fees.sql | 41 ++++++++++ db/views/detail_de_facture.sql | 30 ++++++++ db/views/full_logistic_expense_detail.sql | 51 +++++++++++++ db/views/get_registration_fees.sql | 24 ++++++ db/views/inventory_record.sql | 25 ++++++ db/views/logistic_fees_by_country.sql | 16 ++++ db/views/logistic_profit_analyze.sql | 29 +++++++ ...platform_order_logistic_expense_detail.sql | 35 +++++++++ db/views/sales.sql | 20 +++++ db/views/sales_analyze.sql | 42 ++++++++++ db/views/sav_refund_with_detail.sql | 16 ++++ db/views/sku_country_channel_choice.sql | 25 ++++++ db/views/sku_current_price.sql | 12 +++ db/views/sku_in_platform_order.sql | 5 ++ db/views/sku_price_promotion.sql | 22 ++++++ db/views/sku_weight_discount.sql | 7 ++ 18 files changed, 489 insertions(+) create mode 100644 db/util.sql create mode 100644 db/views/api_view.sql create mode 100644 db/views/calculate_shipping_fees.sql create mode 100644 db/views/detail_de_facture.sql create mode 100644 db/views/full_logistic_expense_detail.sql create mode 100644 db/views/get_registration_fees.sql create mode 100644 db/views/inventory_record.sql create mode 100644 db/views/logistic_fees_by_country.sql create mode 100644 db/views/logistic_profit_analyze.sql create mode 100644 db/views/platform_order_logistic_expense_detail.sql create mode 100644 db/views/sales.sql create mode 100644 db/views/sales_analyze.sql create mode 100644 db/views/sav_refund_with_detail.sql create mode 100644 db/views/sku_country_channel_choice.sql create mode 100644 db/views/sku_current_price.sql create mode 100644 db/views/sku_in_platform_order.sql create mode 100644 db/views/sku_price_promotion.sql create mode 100644 db/views/sku_weight_discount.sql diff --git a/db/util.sql b/db/util.sql new file mode 100644 index 000000000..46b05060f --- /dev/null +++ b/db/util.sql @@ -0,0 +1,76 @@ +SELECT DISTINCT sku_id FROM platform_order_content WHERE sku_id not LIKE '1%'; + +UPDATE platform_order +SET fret_fee = NULL, + shipping_invoice_number = NULL +WHERE shipping_invoice_number IS NOT NULL; +UPDATE platform_order_content +SET shipping_fee = NULL, + service_fee = NULL, + vat = NULL +WHERE vat IS NOT NULL; + +DELETE from platform_order_content WHERE sku_id is NULL; + + +SELECT @@character_set_database, @@collation_database; +SHOW VARIABLES LIKE 'collation%'; +SHOW TABLE STATUS LIKE 'sen%'; +ALTER DATABASE wia_app COLLATE utf8mb4_general_ci; + +SELECT c.internal_code AS '客户', + s.erp_code AS SKU, + p.zh_name AS '中文名', + p.weight AS '重量', + ROUND(calculate_shipping_fees(IF(sa.zh_name = '普货', '联邮通优先挂号-普货', '联邮通优先挂号-带电'), 'FR', '2021-06-24', + p.weight), 2) AS '运费', + get_registration_fees(IF(sa.zh_name = '普货', '联邮通优先挂号-普货', '联邮通优先挂号-带电'), 'FR', '2021-06-24', + p.weight) AS '挂号费' +FROM sku s + LEFT JOIN client_sku ON s.id = client_sku.sku_id + LEFT JOIN client c ON client_sku.client_id = c.id + JOIN product p ON p.id = s.product_id + JOIN sensitive_attribute sa ON p.sensitive_attribute_id = sa.id; + +SELECT c.internal_code AS 'Client', + po.platform_order_id AS 'Order ID', + po.logistic_channel_name AS 'Logistic Channel', + po.platform_order_number AS 'Order Number', + po.order_time AS 'Order Time', + po.shipping_time AS 'Shipping Time', + po.country AS 'Country', + IF(s.erp_code IS NULL, poc.sku_id, s.erp_code) AS 'SKU', + poc.quantity AS 'Quantity', + po.fret_fee AS 'Fret Fee', + (SELECT SUM(poc.shipping_fee) +WHERE poc.platform_order_id = po.id) AS 'Shipping Fee', + poc.service_fee AS 'Service Fee', + po.status AS 'Status' +FROM platform_order po + JOIN platform_order_content poc ON po.id = poc.platform_order_id + LEFT JOIN shop ON po.shop_id = shop.id + LEFT JOIN client c ON shop.owner_id = c.id + LEFT JOIN sku s ON poc.sku_id = s.id +WHERE po.erp_status = 3 +ORDER BY Client; + +SELECT json_array(poc.shipping_fee) +from platform_order_content poc JOIN platform_order po ON po.id = poc.platform_order_id +WHERE poc.platform_order_id = po.id; + +SELECT s.erp_code, count(DISTINCT po.id), sum(poc.quantity) +FROM platform_order po + JOIN platform_order_content poc ON po.id = poc.platform_order_id + JOIN shop s ON po.shop_id = s.id +WHERE shipping_invoice_number IS not NULL + AND po.erp_status = '3' +GROUP BY erp_code +ORDER BY erp_code; + +SELECT s.erp_code, po.* +FROM platform_order po + JOIN platform_order_content poc ON po.id = poc.platform_order_id + JOIN shop s ON po.shop_id = s.id +WHERE shipping_invoice_number IS NULL + AND po.erp_status = '3' and (erp_code = 'EP5' OR erp_code ='EP6') +ORDER BY erp_code; \ No newline at end of file diff --git a/db/views/api_view.sql b/db/views/api_view.sql new file mode 100644 index 000000000..7ad164983 --- /dev/null +++ b/db/views/api_view.sql @@ -0,0 +1,13 @@ +CREATE OR REPLACE VIEW api_view AS +SELECT p.country, p.third_bill_code as trackingNumber, + (SELECT JSON_ARRAYAGG( + JSON_OBJECT( + 'scanType', scan_type, + 'scanTime', scan_time, + 'description', IF(description_en IS NOT NULL, description_en, description) + )) + FROM parcel_trace pt + WHERE p.id = pt.parcel_id + ORDER BY scan_time DESC + ) AS traces +FROM parcel p; \ No newline at end of file diff --git a/db/views/calculate_shipping_fees.sql b/db/views/calculate_shipping_fees.sql new file mode 100644 index 000000000..ae27b9966 --- /dev/null +++ b/db/views/calculate_shipping_fees.sql @@ -0,0 +1,41 @@ +CREATE FUNCTION calculate_shipping_fees(logistic_channel varchar(50), country varchar(2), shipping_date date, + weight int) RETURNS DOUBLE +BEGIN + DECLARE minimum_weight INT; + DECLARE minimum_weight_price double; + DECLARE cal_unit INT; + DECLARE cal_unit_price double; + DECLARE additional_cost double; + DECLARE shipping_fee double; + + SELECT lcp.minimum_weight, + lcp.minimum_weight_price, + lcp.cal_unit, + lcp.cal_unit_price, + lcp.additional_cost + INTO minimum_weight, + minimum_weight_price, + cal_unit, + cal_unit_price, + additional_cost + FROM logistic_channel_price lcp + JOIN logistic_channel lc ON lc.id = lcp.channel_id + WHERE lc.zh_name = logistic_channel + AND weight_range_start <= weight + AND weight_range_end >= weight + AND effective_country = country + AND effective_date <= shipping_date + ORDER BY effective_date + DESC + LIMIT 1; + + IF weight = 0 THEN + SET shipping_fee = 0; + ELSEIF weight < minimum_weight THEN + SET shipping_fee = minimum_weight_price; + ELSE + SET shipping_fee = ((weight - minimum_weight) / cal_unit) * cal_unit_price + minimum_weight_price; + END IF; + + RETURN shipping_fee; +END; \ No newline at end of file diff --git a/db/views/detail_de_facture.sql b/db/views/detail_de_facture.sql new file mode 100644 index 000000000..b3ba2ceae --- /dev/null +++ b/db/views/detail_de_facture.sql @@ -0,0 +1,30 @@ +CREATE OR REPLACE VIEW detail_de_facture AS +SELECT s.name AS 'Boutique', + po.platform_order_id AS 'N° de Mabang', + po.platform_order_number AS 'N° de commande', + po.tracking_number AS 'N° de suivi', + po.order_time AS 'Date de commande', + po.shipping_time AS 'Date d\'expédition', + po.recipient AS 'Nom de client', + po.country AS 'Pays', + po.postcode AS 'Code postal', + JSON_ARRAYAGG(sku.erp_code) AS 'SKU', + JSON_ARRAYAGG(p.en_name) AS 'Nom produits', + JSON_ARRAYAGG(poc.quantity) AS 'Quantité', + SUM(poc.purchase_fee) AS 'Frais d\'achat', + po.fret_fee AS 'Frais de FRET', + SUM(poc.shipping_fee) AS 'Frais de livraison', + po.order_service_fee + SUM(poc.service_fee) AS 'Frais de service', + po.picking_fee + SUM(poc.picking_fee) AS 'Frais de préparation', + po.packaging_material_fee AS 'Frais de matériel d\'emballage', + SUM(poc.vat) AS 'TVA', + po.shipping_invoice_number AS 'N° de facture' +FROM platform_order po + JOIN shop s ON po.shop_id = s.id + RIGHT JOIN platform_order_content poc ON po.id = poc.platform_order_id + JOIN sku ON poc.sku_id = sku.id + JOIN product p ON sku.product_id = p.id +WHERE shipping_invoice_number IS NOT NULL + AND poc.erp_status <> 5 +GROUP BY po.id, s.name, po.order_time +ORDER BY s.name, po.order_time; \ No newline at end of file diff --git a/db/views/full_logistic_expense_detail.sql b/db/views/full_logistic_expense_detail.sql new file mode 100644 index 000000000..0322baa73 --- /dev/null +++ b/db/views/full_logistic_expense_detail.sql @@ -0,0 +1,51 @@ +CREATE OR REPLACE VIEW full_logistic_expense_detail AS +SELECT led.tracking_number AS 'trackingNumber', + led.real_weight, + led.volumetric_weight, + led.charging_weight, + led.discount, + led.shipping_fee, + led.fuel_surcharge, + led.registration_fee, + led.second_delivery_fee, + led.vat, + led.vat_service_fee, + led.total_fee, + led.logistic_company_id, + led.additional_fee +FROM logistic_expense_detail led +WHERE tracking_number = logistic_internal_number +UNION +SELECT led.logistic_internal_number AS 'trackingNumber', + led.real_weight, + led.volumetric_weight, + led.charging_weight, + led.discount, + led.shipping_fee, + led.fuel_surcharge, + led.registration_fee, + led.second_delivery_fee, + led.vat, + led.vat_service_fee, + led.total_fee, + led.logistic_company_id, + led.additional_fee +FROM logistic_expense_detail led +WHERE tracking_number <> logistic_internal_number +UNION +SELECT led.tracking_number AS 'trackingNumber', + led.real_weight, + led.volumetric_weight, + led.charging_weight, + led.discount, + led.shipping_fee, + led.fuel_surcharge, + led.registration_fee, + led.second_delivery_fee, + led.vat, + led.vat_service_fee, + led.total_fee, + led.logistic_company_id, + led.additional_fee +FROM logistic_expense_detail led +WHERE tracking_number <> logistic_internal_number; \ No newline at end of file diff --git a/db/views/get_registration_fees.sql b/db/views/get_registration_fees.sql new file mode 100644 index 000000000..4f0f5ee85 --- /dev/null +++ b/db/views/get_registration_fees.sql @@ -0,0 +1,24 @@ +CREATE FUNCTION get_registration_fees(logistic_channel varchar(50), country varchar(2), shipping_date date, + weight int) RETURNS DOUBLE +BEGIN + DECLARE registration_fee double; + + SELECT lcp.registration_fee + INTO registration_fee + FROM logistic_channel_price lcp + JOIN logistic_channel lc ON lc.id = lcp.channel_id + WHERE lc.zh_name = logistic_channel + AND weight_range_start <= weight + AND weight_range_end >= weight + AND effective_country = country + AND effective_date <= shipping_date + ORDER BY effective_date + DESC + LIMIT 1; + + IF weight = 0 THEN + RETURN 0; + ELSE + RETURN registration_fee; + END IF; +END; \ No newline at end of file diff --git a/db/views/inventory_record.sql b/db/views/inventory_record.sql new file mode 100644 index 000000000..42d2d9b6a --- /dev/null +++ b/db/views/inventory_record.sql @@ -0,0 +1,25 @@ +CREATE OR REPLACE VIEW inventory_record AS +SELECT sku.id AS id, + cs.client_id AS client_id, + sku.product_id AS product_id, + sku.erp_code AS erp_code, + sku.image_source AS image_source, + sku.available_amount AS available_amount, + p.moq AS moq, + rs.quantity AS red_quantity, + gs.quantity AS green_quantity, + sales_7.quantity AS sales_7, + sales_14.quantity AS sales_14, + sales_28.quantity AS sales_28, + sipo.quantity AS platform_order_quantity +FROM sku + JOIN product p ON sku.product_id = p.id + JOIN client_sku cs ON sku.id = cs.sku_id + LEFT JOIN sales_7 ON sku.id = sales_7.sku_id + LEFT JOIN sales_14 ON sku.id = sales_14.sku_id + LEFT JOIN sales_28 ON sku.id = sales_28.sku_id + LEFT JOIN red_sku rs ON sku.id = rs.sku_id + LEFT JOIN green_sku gs ON sku.id = gs.sku_id + LEFT JOIN sku_in_platform_order sipo ON sku.id = sipo.sku_id +ORDER BY platform_order_quantity DESC; + diff --git a/db/views/logistic_fees_by_country.sql b/db/views/logistic_fees_by_country.sql new file mode 100644 index 000000000..313524f57 --- /dev/null +++ b/db/views/logistic_fees_by_country.sql @@ -0,0 +1,16 @@ +CREATE OR REPLACE VIEW logistic_fees_by_country AS +SELECT s.name AS '店铺', + po.country AS '国家', + SUM(po.fret_fee) AS '收取挂号费', + SUM(led.registration_fee) AS '实际支付挂号费', + SUM(poc.shipping_fee) AS '收取运费', + SUM(led.total_fee) - SUM(registration_fee) AS '实际支付运费', + SUM(poc.vat) AS '收取TVA', + SUM(led.vat) + SUM(led.vat_service_fee) AS '实际支付TVA' +FROM platform_order po + JOIN shop s ON po.shop_id = s.id + RIGHT JOIN platform_order_content poc ON po.id = poc.platform_order_id + JOIN logistic_expense_detail led ON po.tracking_number = led.tracking_number +WHERE shipping_invoice_number IS NOT NULL +GROUP BY s.name, po.country +ORDER BY s.name \ No newline at end of file diff --git a/db/views/logistic_profit_analyze.sql b/db/views/logistic_profit_analyze.sql new file mode 100644 index 000000000..bff9ffc81 --- /dev/null +++ b/db/views/logistic_profit_analyze.sql @@ -0,0 +1,29 @@ +CREATE OR REPLACE VIEW logistic_profit_analyze AS +SELECT c.internal_code AS '客户', + shopErpCode AS '店铺', + lc.name AS '物流公司', + logisticChannelName AS '物流路线', + platformOrderId AS '订单号', + platformOrderNumber AS '交易号', + orderTime AS '交易时间', + shippingTime AS '发货时间', + poled.country AS '国家', + fretFee AS '应收挂号费(欧元)', + registration_fee AS '实付挂号费(人民币)', + (fretFee * 7.6 - registration_fee) AS '挂号费利润(人民币)', + shippingFee AS '应收运费(欧元)', + realShippingFee AS '实付运费(人民币)', + (shippingFee * 7.6 - realShippingFee) AS '运费利润(人民币)', + vatFee AS '应收增值税(欧元)', + (vat + vat_service_fee) AS '实付增值税(人民币)', + (vatFee * 7.6 - vat - vat_service_fee) AS '增值税利润(人民币)', + serviceFee AS '服务费(欧元)', + serviceFee * 7.6 AS '服务费(人民币)', + (fretFee * 7.6 - registration_fee + shippingFee * 7.6 - + realShippingFee + vat * 7.6 - vat - vat_service_fee) AS '服务费外总利润(人民币)' + +FROM platform_order_logistic_expense_detail poled + JOIN shop s + ON shop_id = s.id + JOIN CLIENT c ON s.owner_id = c.id + JOIN logistic_company lc ON poled.logistic_company_id = lc.id; \ No newline at end of file diff --git a/db/views/platform_order_logistic_expense_detail.sql b/db/views/platform_order_logistic_expense_detail.sql new file mode 100644 index 000000000..8987f6100 --- /dev/null +++ b/db/views/platform_order_logistic_expense_detail.sql @@ -0,0 +1,35 @@ +CREATE OR REPLACE VIEW platform_order_logistic_expense_detail AS +SELECT s.erp_code AS 'shopErpCode', + po.tracking_number AS 'trackingNumber', + po.shop_id, + po.logistic_channel_name AS 'logisticChannelName', + po.platform_order_id AS 'platformOrderId', + po.platform_order_number AS 'platformOrderNumber', + po.order_time AS 'orderTime', + po.shipping_time AS 'shippingTime', + po.country, + po.fret_fee AS 'fretFee', + SUM(poc.shipping_fee) AS 'shippingFee', + SUM(poc.vat) AS 'vatFee', + po.order_service_fee + SUM(poc.service_fee) AS 'serviceFee', + po.shipping_invoice_number AS 'shippingInvoiceNumber', + fled.real_weight, + fled.volumetric_weight, + fled.charging_weight, + fled.discount, + fled.shipping_fee AS 'realShippingFee', + fled.fuel_surcharge, + fled.registration_fee, + fled.second_delivery_fee, + fled.vat, + fled.vat_service_fee, + fled.total_fee, + fled.logistic_company_id, + fled.additional_fee +FROM full_logistic_expense_detail fled + RIGHT JOIN platform_order po ON fled.trackingNumber = po.tracking_number + JOIN shop s ON po.shop_id = s.id + JOIN platform_order_content poc ON po.id = poc.platform_order_id +WHERE po.erp_status IN (3, 4) +GROUP BY po.id, s.erp_code +ORDER BY s.erp_code; \ No newline at end of file diff --git a/db/views/sales.sql b/db/views/sales.sql new file mode 100644 index 000000000..852a2ca21 --- /dev/null +++ b/db/views/sales.sql @@ -0,0 +1,20 @@ +CREATE OR REPLACE VIEW sales_7 AS +SELECT poc.sku_id AS sku_id, SUM(poc.quantity) AS quantity +FROM platform_order_content poc + JOIN platform_order po ON poc.platform_order_id = po.id +WHERE po.order_time BETWEEN DATE_SUB(CURDATE(), INTERVAL 7 DAY) AND CURDATE() +GROUP BY poc.sku_id; + +CREATE OR REPLACE VIEW sales_14 AS +SELECT poc.sku_id AS sku_id, SUM(poc.quantity) AS quantity +FROM platform_order_content poc + JOIN platform_order po ON poc.platform_order_id = po.id +WHERE po.order_time BETWEEN DATE_SUB(CURDATE(), INTERVAL 14 DAY) AND CURDATE() +GROUP BY poc.sku_id; + +CREATE OR REPLACE VIEW sales_28 AS +SELECT poc.sku_id AS sku_id, SUM(poc.quantity) AS quantity +FROM platform_order_content poc + JOIN platform_order po ON poc.platform_order_id = po.id +WHERE po.order_time BETWEEN DATE_SUB(CURDATE(), INTERVAL 28 DAY) AND CURDATE() +GROUP BY poc.sku_id; \ No newline at end of file diff --git a/db/views/sales_analyze.sql b/db/views/sales_analyze.sql new file mode 100644 index 000000000..07a5b21c4 --- /dev/null +++ b/db/views/sales_analyze.sql @@ -0,0 +1,42 @@ +CREATE OR REPLACE VIEW sales_analyze AS +SELECT c.internal_code AS '客户代码', + s.name AS '店铺名', + s.erp_code AS '店铺代码', + po.platform_order_number AS '订单交易号', + po.country AS '国家', + po.order_time AS '订单交易时间', + CAST(po.order_time AS DATE) AS '订单交易日期', + CASE + WHEN + s2.erp_code IS NULL + THEN poc.sku_id + WHEN s2.erp_code IS NOT NULL + THEN s2.erp_code + END AS 'SKU', + p.zh_name AS '产品中文名', + poc.quantity AS '产品数量', + p.weight AS '商品收费重', + poc.purchase_fee AS '商品采购费', + poc.service_fee AS '商品服务费', + poc.shipping_fee AS '商品运费', + po.fret_fee AS '包裹挂号费', + CASE + WHEN po.erp_status = '1' + THEN '待处理' + WHEN po.erp_status = '2' + THEN '配货中' + WHEN po.erp_status = '3' + THEN '已发货' + WHEN po.erp_status = '4' + THEN '已完成' + WHEN po.erp_status = '5' + THEN '已作废' + END AS '订单状态', + po.logistic_channel_name AS '物流渠道' +FROM platform_order_content poc + LEFT JOIN sku s2 ON poc.sku_id = s2.id + LEFT JOIN product p ON s2.product_id = p.id + JOIN platform_order po ON poc.platform_order_id = po.id + JOIN shop s ON po.shop_id = s.id + JOIN client c ON s.owner_id = c.id +ORDER BY order_time; \ No newline at end of file diff --git a/db/views/sav_refund_with_detail.sql b/db/views/sav_refund_with_detail.sql new file mode 100644 index 000000000..140276692 --- /dev/null +++ b/db/views/sav_refund_with_detail.sql @@ -0,0 +1,16 @@ +CREATE OR REPLACE VIEW sav_refund_with_detail +AS +SELECT sr.*, + po.platform_order_id AS mabang_id, + s.erp_code, + s.name as shop_name, + po.platform_order_number, + po.fret_fee, + SUM(poc.shipping_fee) AS shipping_fee, + SUM(poc.vat) AS vat, + po.order_service_fee + SUM(poc.service_fee) AS service_fee +FROM sav_refund sr + JOIN platform_order po ON sr.platform_order_id = po.id + JOIN platform_order_content poc ON po.id = poc.platform_order_id + JOIN shop s ON po.shop_id = s.id +GROUP BY po.id; \ No newline at end of file diff --git a/db/views/sku_country_channel_choice.sql b/db/views/sku_country_channel_choice.sql new file mode 100644 index 000000000..7fbb17826 --- /dev/null +++ b/db/views/sku_country_channel_choice.sql @@ -0,0 +1,25 @@ +CREATE OR REPLACE VIEW sku_country_channel_choice AS +SELECT sku.id AS id, + cs.client_id AS client_id, + sku.product_id AS product_id, + sku.erp_code AS erp_code, + sku.image_source AS image_source, + sku.available_amount AS available_amount, + p.moq AS moq, + rs.quantity AS red_quantity, + gs.quantity AS green_quantity, + sales_7.quantity AS sales_7, + sales_14.quantity AS sales_14, + sales_28.quantity AS sales_28, + sipo.quantity AS platform_order_quantity +FROM sku + JOIN product p ON sku.product_id = p.id + JOIN client_sku cs ON sku.id = cs.sku_id + LEFT JOIN sales_7 ON sku.id = sales_7.sku_id + LEFT JOIN sales_14 ON sku.id = sales_14.sku_id + LEFT JOIN sales_28 ON sku.id = sales_28.sku_id + LEFT JOIN red_sku rs ON sku.id = rs.sku_id + LEFT JOIN green_sku gs ON sku.id = gs.sku_id + LEFT JOIN sku_in_platform_order sipo ON sku.id = sipo.sku_id +ORDER BY platform_order_quantity DESC; + diff --git a/db/views/sku_current_price.sql b/db/views/sku_current_price.sql new file mode 100644 index 000000000..4a4728e91 --- /dev/null +++ b/db/views/sku_current_price.sql @@ -0,0 +1,12 @@ +CREATE OR REPLACE VIEW sku_current_price AS +SELECT id AS price_id, + sp.sku_id AS sku_id, + price AS price, + threshold AS threshold, + discounted_price AS discounted_price, + price_rmb AS price_rmb, + discounted_price_rmb AS discounted_price_rmb, + date AS date +FROM sku_price sp + INNER JOIN (SELECT sku_id, MAX(date) max_date FROM sku_price GROUP BY sku_id) sp2 + ON sp.sku_id = sp2.sku_id AND sp.date = sp2.max_date \ No newline at end of file diff --git a/db/views/sku_in_platform_order.sql b/db/views/sku_in_platform_order.sql new file mode 100644 index 000000000..c5bc677a8 --- /dev/null +++ b/db/views/sku_in_platform_order.sql @@ -0,0 +1,5 @@ +CREATE OR REPLACE VIEW sku_in_platform_order AS +SELECT poc.sku_id AS sku_id, SUM(poc.quantity) AS quantity +FROM platform_order_content poc join platform_order po ON poc.platform_order_id = po.id +WHERE po.status = 2 +GROUP BY poc.sku_id; \ No newline at end of file diff --git a/db/views/sku_price_promotion.sql b/db/views/sku_price_promotion.sql new file mode 100644 index 000000000..60d2816c8 --- /dev/null +++ b/db/views/sku_price_promotion.sql @@ -0,0 +1,22 @@ +CREATE OR REPLACE VIEW sku_price_promotion AS +SELECT s.id AS sku_id, + p.en_name AS name_en, + p.zh_name AS name_zh, + s.erp_code AS erp_code, + s.image_source AS image_source, + spr.promotion_id AS promotion_id, + spr.promo_milestone AS promo_milestone, + spr.quantity_purchased AS quantity_purchased, + spr.discount AS discount, + scp.price_id AS price_id, + scp.price AS price, + scp.threshold AS threshold, + scp.discounted_price AS discounted_price, + scp.price_rmb AS price_rmb, + scp.discounted_price_rmb AS discounted_price_rmb +FROM sku s + LEFT JOIN sku_promotion_relation spr ON s.id = spr.sku_id + LEFT JOIN sku_current_price scp ON s.id = scp.sku_id + JOIN product p ON s.product_id = p.id + LEFT JOIN sku_in_platform_order sipo ON s.id = sipo.sku_id +ORDER BY sipo.quantity DESC; \ No newline at end of file diff --git a/db/views/sku_weight_discount.sql b/db/views/sku_weight_discount.sql new file mode 100644 index 000000000..44db099d2 --- /dev/null +++ b/db/views/sku_weight_discount.sql @@ -0,0 +1,7 @@ +CREATE OR REPLACE VIEW sku_weight_discount_service_fees AS +SELECT s.id, + s.erp_code, + p.weight, + s.shipping_discount, + s.service_fee +FROM sku s JOIN product p ON p.id = s.product_id; \ No newline at end of file