Fix specific import calculations
This commit is contained in:
@@ -113,6 +113,8 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
|
|||||||
DROP TABLE IF EXISTS temp_order_discounts;
|
DROP TABLE IF EXISTS temp_order_discounts;
|
||||||
DROP TABLE IF EXISTS temp_order_taxes;
|
DROP TABLE IF EXISTS temp_order_taxes;
|
||||||
DROP TABLE IF EXISTS temp_order_costs;
|
DROP TABLE IF EXISTS temp_order_costs;
|
||||||
|
DROP TABLE IF EXISTS temp_main_discounts;
|
||||||
|
DROP TABLE IF EXISTS temp_item_discounts;
|
||||||
|
|
||||||
CREATE TEMP TABLE temp_order_items (
|
CREATE TEMP TABLE temp_order_items (
|
||||||
order_id INTEGER NOT NULL,
|
order_id INTEGER NOT NULL,
|
||||||
@@ -144,6 +146,21 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
|
|||||||
PRIMARY KEY (order_id, pid)
|
PRIMARY KEY (order_id, pid)
|
||||||
);
|
);
|
||||||
|
|
||||||
|
CREATE TEMP TABLE temp_main_discounts (
|
||||||
|
order_id INTEGER NOT NULL,
|
||||||
|
discount_id INTEGER NOT NULL,
|
||||||
|
discount_amount_subtotal NUMERIC(14, 4) DEFAULT 0.0000,
|
||||||
|
PRIMARY KEY (order_id, discount_id)
|
||||||
|
);
|
||||||
|
|
||||||
|
CREATE TEMP TABLE temp_item_discounts (
|
||||||
|
order_id INTEGER NOT NULL,
|
||||||
|
pid INTEGER NOT NULL,
|
||||||
|
discount_id INTEGER NOT NULL,
|
||||||
|
amount NUMERIC(14, 4) NOT NULL,
|
||||||
|
PRIMARY KEY (order_id, pid, discount_id)
|
||||||
|
);
|
||||||
|
|
||||||
CREATE TEMP TABLE temp_order_taxes (
|
CREATE TEMP TABLE temp_order_taxes (
|
||||||
order_id INTEGER NOT NULL,
|
order_id INTEGER NOT NULL,
|
||||||
pid INTEGER NOT NULL,
|
pid INTEGER NOT NULL,
|
||||||
@@ -163,6 +180,9 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
|
|||||||
CREATE INDEX idx_temp_order_discounts_order_pid ON temp_order_discounts(order_id, pid);
|
CREATE INDEX idx_temp_order_discounts_order_pid ON temp_order_discounts(order_id, pid);
|
||||||
CREATE INDEX idx_temp_order_taxes_order_pid ON temp_order_taxes(order_id, pid);
|
CREATE INDEX idx_temp_order_taxes_order_pid ON temp_order_taxes(order_id, pid);
|
||||||
CREATE INDEX idx_temp_order_costs_order_pid ON temp_order_costs(order_id, pid);
|
CREATE INDEX idx_temp_order_costs_order_pid ON temp_order_costs(order_id, pid);
|
||||||
|
CREATE INDEX idx_temp_main_discounts_discount_id ON temp_main_discounts(discount_id);
|
||||||
|
CREATE INDEX idx_temp_item_discounts_order_pid ON temp_item_discounts(order_id, pid);
|
||||||
|
CREATE INDEX idx_temp_item_discounts_discount_id ON temp_item_discounts(discount_id);
|
||||||
`);
|
`);
|
||||||
await localConnection.commit();
|
await localConnection.commit();
|
||||||
} catch (error) {
|
} catch (error) {
|
||||||
@@ -296,38 +316,97 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
|
|||||||
};
|
};
|
||||||
|
|
||||||
const processDiscountsBatch = async (batchIds) => {
|
const processDiscountsBatch = async (batchIds) => {
|
||||||
|
// First, load main discount records
|
||||||
|
const [mainDiscounts] = await prodConnection.query(`
|
||||||
|
SELECT order_id, discount_id, discount_amount_subtotal
|
||||||
|
FROM order_discounts
|
||||||
|
WHERE order_id IN (?)
|
||||||
|
`, [batchIds]);
|
||||||
|
|
||||||
|
if (mainDiscounts.length > 0) {
|
||||||
|
await localConnection.beginTransaction();
|
||||||
|
try {
|
||||||
|
for (let j = 0; j < mainDiscounts.length; j += PG_BATCH_SIZE) {
|
||||||
|
const subBatch = mainDiscounts.slice(j, j + PG_BATCH_SIZE);
|
||||||
|
if (subBatch.length === 0) continue;
|
||||||
|
|
||||||
|
const placeholders = subBatch.map((_, idx) =>
|
||||||
|
`($${idx * 3 + 1}, $${idx * 3 + 2}, $${idx * 3 + 3})`
|
||||||
|
).join(",");
|
||||||
|
|
||||||
|
const values = subBatch.flatMap(d => [
|
||||||
|
d.order_id,
|
||||||
|
d.discount_id,
|
||||||
|
d.discount_amount_subtotal || 0
|
||||||
|
]);
|
||||||
|
|
||||||
|
await localConnection.query(`
|
||||||
|
INSERT INTO temp_main_discounts (order_id, discount_id, discount_amount_subtotal)
|
||||||
|
VALUES ${placeholders}
|
||||||
|
ON CONFLICT (order_id, discount_id) DO UPDATE SET
|
||||||
|
discount_amount_subtotal = EXCLUDED.discount_amount_subtotal
|
||||||
|
`, values);
|
||||||
|
}
|
||||||
|
await localConnection.commit();
|
||||||
|
} catch (error) {
|
||||||
|
await localConnection.rollback();
|
||||||
|
throw error;
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
|
// Then, load item discount records
|
||||||
const [discounts] = await prodConnection.query(`
|
const [discounts] = await prodConnection.query(`
|
||||||
SELECT order_id, pid, SUM(amount) as discount
|
SELECT order_id, pid, discount_id, amount
|
||||||
FROM order_discount_items
|
FROM order_discount_items
|
||||||
WHERE order_id IN (?)
|
WHERE order_id IN (?)
|
||||||
GROUP BY order_id, pid
|
|
||||||
`, [batchIds]);
|
`, [batchIds]);
|
||||||
|
|
||||||
if (discounts.length === 0) return;
|
if (discounts.length === 0) return;
|
||||||
|
|
||||||
|
// Process in memory to handle potential duplicates
|
||||||
|
const discountMap = new Map();
|
||||||
|
for (const d of discounts) {
|
||||||
|
const key = `${d.order_id}-${d.pid}-${d.discount_id}`;
|
||||||
|
discountMap.set(key, d);
|
||||||
|
}
|
||||||
|
|
||||||
|
const uniqueDiscounts = Array.from(discountMap.values());
|
||||||
|
|
||||||
await localConnection.beginTransaction();
|
await localConnection.beginTransaction();
|
||||||
try {
|
try {
|
||||||
for (let j = 0; j < discounts.length; j += PG_BATCH_SIZE) {
|
for (let j = 0; j < uniqueDiscounts.length; j += PG_BATCH_SIZE) {
|
||||||
const subBatch = discounts.slice(j, j + PG_BATCH_SIZE);
|
const subBatch = uniqueDiscounts.slice(j, j + PG_BATCH_SIZE);
|
||||||
if (subBatch.length === 0) continue;
|
if (subBatch.length === 0) continue;
|
||||||
|
|
||||||
const placeholders = subBatch.map((_, idx) =>
|
const placeholders = subBatch.map((_, idx) =>
|
||||||
`($${idx * 3 + 1}, $${idx * 3 + 2}, $${idx * 3 + 3})`
|
`($${idx * 4 + 1}, $${idx * 4 + 2}, $${idx * 4 + 3}, $${idx * 4 + 4})`
|
||||||
).join(",");
|
).join(",");
|
||||||
|
|
||||||
const values = subBatch.flatMap(d => [
|
const values = subBatch.flatMap(d => [
|
||||||
d.order_id,
|
d.order_id,
|
||||||
d.pid,
|
d.pid,
|
||||||
d.discount || 0
|
d.discount_id,
|
||||||
|
d.amount || 0
|
||||||
]);
|
]);
|
||||||
|
|
||||||
await localConnection.query(`
|
await localConnection.query(`
|
||||||
INSERT INTO temp_order_discounts (order_id, pid, discount)
|
INSERT INTO temp_item_discounts (order_id, pid, discount_id, amount)
|
||||||
VALUES ${placeholders}
|
VALUES ${placeholders}
|
||||||
ON CONFLICT (order_id, pid) DO UPDATE SET
|
ON CONFLICT (order_id, pid, discount_id) DO UPDATE SET
|
||||||
discount = EXCLUDED.discount
|
amount = EXCLUDED.amount
|
||||||
`, values);
|
`, values);
|
||||||
}
|
}
|
||||||
|
|
||||||
|
// Create aggregated view with a simpler, safer query that avoids duplicates
|
||||||
|
await localConnection.query(`
|
||||||
|
TRUNCATE temp_order_discounts;
|
||||||
|
|
||||||
|
INSERT INTO temp_order_discounts (order_id, pid, discount)
|
||||||
|
SELECT order_id, pid, SUM(amount) as discount
|
||||||
|
FROM temp_item_discounts
|
||||||
|
GROUP BY order_id, pid
|
||||||
|
`);
|
||||||
|
|
||||||
await localConnection.commit();
|
await localConnection.commit();
|
||||||
} catch (error) {
|
} catch (error) {
|
||||||
await localConnection.rollback();
|
await localConnection.rollback();
|
||||||
@@ -485,11 +564,16 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
|
|||||||
SELECT
|
SELECT
|
||||||
oi.order_id,
|
oi.order_id,
|
||||||
oi.pid,
|
oi.pid,
|
||||||
SUM(COALESCE(od.discount, 0)) as promo_discount,
|
-- Instead of using ARRAY_AGG which can cause duplicate issues, use SUM with a CASE
|
||||||
|
SUM(CASE
|
||||||
|
WHEN COALESCE(md.discount_amount_subtotal, 0) > 0 THEN id.amount
|
||||||
|
ELSE 0
|
||||||
|
END) as promo_discount_sum,
|
||||||
COALESCE(ot.tax, 0) as total_tax,
|
COALESCE(ot.tax, 0) as total_tax,
|
||||||
COALESCE(oc.costeach, oi.price * 0.5) as costeach
|
COALESCE(oc.costeach, oi.price * 0.5) as costeach
|
||||||
FROM temp_order_items oi
|
FROM temp_order_items oi
|
||||||
LEFT JOIN temp_order_discounts od ON oi.order_id = od.order_id AND oi.pid = od.pid
|
LEFT JOIN temp_item_discounts id ON oi.order_id = id.order_id AND oi.pid = id.pid
|
||||||
|
LEFT JOIN temp_main_discounts md ON id.order_id = md.order_id AND id.discount_id = md.discount_id
|
||||||
LEFT JOIN temp_order_taxes ot ON oi.order_id = ot.order_id AND oi.pid = ot.pid
|
LEFT JOIN temp_order_taxes ot ON oi.order_id = ot.order_id AND oi.pid = ot.pid
|
||||||
LEFT JOIN temp_order_costs oc ON oi.order_id = oc.order_id AND oi.pid = oc.pid
|
LEFT JOIN temp_order_costs oc ON oi.order_id = oc.order_id AND oi.pid = oc.pid
|
||||||
WHERE oi.order_id = ANY($1)
|
WHERE oi.order_id = ANY($1)
|
||||||
@@ -513,8 +597,8 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
|
|||||||
ELSE 0
|
ELSE 0
|
||||||
END
|
END
|
||||||
+
|
+
|
||||||
-- Part 3: Specific Promo Code Discount (if applicable)
|
-- Part 3: Specific Item-Level Discount (only if parent discount affected subtotal)
|
||||||
COALESCE(ot.promo_discount, 0)
|
COALESCE(ot.promo_discount_sum, 0)
|
||||||
)::NUMERIC(14, 4) as discount,
|
)::NUMERIC(14, 4) as discount,
|
||||||
COALESCE(ot.total_tax, 0)::NUMERIC(14, 4) as tax,
|
COALESCE(ot.total_tax, 0)::NUMERIC(14, 4) as tax,
|
||||||
false as tax_included,
|
false as tax_included,
|
||||||
@@ -649,6 +733,8 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
|
|||||||
DROP TABLE IF EXISTS temp_order_discounts;
|
DROP TABLE IF EXISTS temp_order_discounts;
|
||||||
DROP TABLE IF EXISTS temp_order_taxes;
|
DROP TABLE IF EXISTS temp_order_taxes;
|
||||||
DROP TABLE IF EXISTS temp_order_costs;
|
DROP TABLE IF EXISTS temp_order_costs;
|
||||||
|
DROP TABLE IF EXISTS temp_main_discounts;
|
||||||
|
DROP TABLE IF EXISTS temp_item_discounts;
|
||||||
`);
|
`);
|
||||||
|
|
||||||
// Commit final transaction
|
// Commit final transaction
|
||||||
|
|||||||
@@ -194,7 +194,10 @@ async function importMissingProducts(prodConnection, localConnection, missingPid
|
|||||||
p.country_of_origin,
|
p.country_of_origin,
|
||||||
(SELECT COUNT(*) FROM mybasket mb WHERE mb.item = p.pid AND mb.qty > 0) AS baskets,
|
(SELECT COUNT(*) FROM mybasket mb WHERE mb.item = p.pid AND mb.qty > 0) AS baskets,
|
||||||
(SELECT COUNT(*) FROM product_notify pn WHERE pn.pid = p.pid) AS notifies,
|
(SELECT COUNT(*) FROM product_notify pn WHERE pn.pid = p.pid) AS notifies,
|
||||||
(SELECT COALESCE(SUM(oi.qty_ordered), 0) FROM order_items oi WHERE oi.prod_pid = p.pid) AS total_sold,
|
(SELECT COALESCE(SUM(oi.qty_ordered), 0)
|
||||||
|
FROM order_items oi
|
||||||
|
JOIN _order o ON oi.order_id = o.order_id
|
||||||
|
WHERE oi.prod_pid = p.pid AND o.order_status >= 20) AS total_sold,
|
||||||
pls.date_sold as date_last_sold,
|
pls.date_sold as date_last_sold,
|
||||||
(SELECT iid FROM product_images WHERE pid = p.pid AND \`order\` = 255 LIMIT 1) AS primary_iid,
|
(SELECT iid FROM product_images WHERE pid = p.pid AND \`order\` = 255 LIMIT 1) AS primary_iid,
|
||||||
GROUP_CONCAT(DISTINCT CASE
|
GROUP_CONCAT(DISTINCT CASE
|
||||||
@@ -397,7 +400,10 @@ async function materializeCalculations(prodConnection, localConnection, incremen
|
|||||||
p.country_of_origin,
|
p.country_of_origin,
|
||||||
(SELECT COUNT(*) FROM mybasket mb WHERE mb.item = p.pid AND mb.qty > 0) AS baskets,
|
(SELECT COUNT(*) FROM mybasket mb WHERE mb.item = p.pid AND mb.qty > 0) AS baskets,
|
||||||
(SELECT COUNT(*) FROM product_notify pn WHERE pn.pid = p.pid) AS notifies,
|
(SELECT COUNT(*) FROM product_notify pn WHERE pn.pid = p.pid) AS notifies,
|
||||||
(SELECT COALESCE(SUM(oi.qty_ordered), 0) FROM order_items oi WHERE oi.prod_pid = p.pid) AS total_sold,
|
(SELECT COALESCE(SUM(oi.qty_ordered), 0)
|
||||||
|
FROM order_items oi
|
||||||
|
JOIN _order o ON oi.order_id = o.order_id
|
||||||
|
WHERE oi.prod_pid = p.pid AND o.order_status >= 20) AS total_sold,
|
||||||
pls.date_sold as date_last_sold,
|
pls.date_sold as date_last_sold,
|
||||||
(SELECT iid FROM product_images WHERE pid = p.pid AND \`order\` = 255 LIMIT 1) AS primary_iid,
|
(SELECT iid FROM product_images WHERE pid = p.pid AND \`order\` = 255 LIMIT 1) AS primary_iid,
|
||||||
GROUP_CONCAT(DISTINCT CASE
|
GROUP_CONCAT(DISTINCT CASE
|
||||||
|
|||||||
@@ -31,7 +31,8 @@ BEGIN
|
|||||||
p.stock_quantity as current_stock, -- Use actual current stock for forecast base
|
p.stock_quantity as current_stock, -- Use actual current stock for forecast base
|
||||||
p.created_at, p.first_received, p.date_last_sold,
|
p.created_at, p.first_received, p.date_last_sold,
|
||||||
p.moq,
|
p.moq,
|
||||||
p.uom
|
p.uom,
|
||||||
|
p.total_sold as historical_total_sold -- Add historical total_sold from products table
|
||||||
FROM public.products p
|
FROM public.products p
|
||||||
),
|
),
|
||||||
OnOrderInfo AS (
|
OnOrderInfo AS (
|
||||||
@@ -99,9 +100,30 @@ BEGIN
|
|||||||
AVG(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '29 days' AND _calculation_date THEN eod_stock_retail END) AS avg_stock_retail_30d,
|
AVG(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '29 days' AND _calculation_date THEN eod_stock_retail END) AS avg_stock_retail_30d,
|
||||||
AVG(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '29 days' AND _calculation_date THEN eod_stock_gross END) AS avg_stock_gross_30d,
|
AVG(CASE WHEN snapshot_date BETWEEN _calculation_date - INTERVAL '29 days' AND _calculation_date THEN eod_stock_gross END) AS avg_stock_gross_30d,
|
||||||
|
|
||||||
-- Lifetime (Sum over ALL available snapshots up to calculation date)
|
-- Lifetime (Using product.total_sold instead of snapshot summation for historical accuracy)
|
||||||
SUM(units_sold) AS lifetime_sales,
|
p.historical_total_sold AS lifetime_sales,
|
||||||
SUM(net_revenue) AS lifetime_revenue,
|
COALESCE(
|
||||||
|
-- Option 1: Use 30-day average price if available
|
||||||
|
CASE WHEN SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '29 days' AND snapshot_date <= _calculation_date THEN units_sold ELSE 0 END) > 0 THEN
|
||||||
|
p.historical_total_sold * (
|
||||||
|
SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '29 days' AND snapshot_date <= _calculation_date THEN net_revenue ELSE 0 END) /
|
||||||
|
NULLIF(SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '29 days' AND snapshot_date <= _calculation_date THEN units_sold ELSE 0 END), 0)
|
||||||
|
)
|
||||||
|
ELSE NULL END,
|
||||||
|
-- Option 2: Try 365-day average price if available
|
||||||
|
CASE WHEN SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '364 days' AND snapshot_date <= _calculation_date THEN units_sold ELSE 0 END) > 0 THEN
|
||||||
|
p.historical_total_sold * (
|
||||||
|
SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '364 days' AND snapshot_date <= _calculation_date THEN net_revenue ELSE 0 END) /
|
||||||
|
NULLIF(SUM(CASE WHEN snapshot_date >= _calculation_date - INTERVAL '364 days' AND snapshot_date <= _calculation_date THEN units_sold ELSE 0 END), 0)
|
||||||
|
)
|
||||||
|
ELSE NULL END,
|
||||||
|
-- Option 3: Use current price from products table
|
||||||
|
p.historical_total_sold * p.current_price,
|
||||||
|
-- Option 4: Use regular price if current price might be zero
|
||||||
|
p.historical_total_sold * p.current_regular_price,
|
||||||
|
-- Final fallback: Use accumulated revenue (less accurate for old products)
|
||||||
|
SUM(net_revenue)
|
||||||
|
) AS lifetime_revenue,
|
||||||
|
|
||||||
-- Yesterday (Sales for the specific _calculation_date)
|
-- Yesterday (Sales for the specific _calculation_date)
|
||||||
SUM(CASE WHEN snapshot_date = _calculation_date THEN units_sold ELSE 0 END) as yesterday_sales
|
SUM(CASE WHEN snapshot_date = _calculation_date THEN units_sold ELSE 0 END) as yesterday_sales
|
||||||
|
|||||||
@@ -57,6 +57,7 @@ BEGIN
|
|||||||
p.created_at,
|
p.created_at,
|
||||||
p.first_received,
|
p.first_received,
|
||||||
p.date_last_sold,
|
p.date_last_sold,
|
||||||
|
p.total_sold as historical_total_sold, -- Add historical total_sold from products table
|
||||||
p.uom -- Assuming UOM logic is handled elsewhere or simple (e.g., 1=each)
|
p.uom -- Assuming UOM logic is handled elsewhere or simple (e.g., 1=each)
|
||||||
FROM public.products p
|
FROM public.products p
|
||||||
),
|
),
|
||||||
@@ -255,9 +256,25 @@ BEGIN
|
|||||||
sa.stockout_days_30d, sa.sales_365d, sa.revenue_365d,
|
sa.stockout_days_30d, sa.sales_365d, sa.revenue_365d,
|
||||||
sa.avg_stock_units_30d, sa.avg_stock_cost_30d, sa.avg_stock_retail_30d, sa.avg_stock_gross_30d,
|
sa.avg_stock_units_30d, sa.avg_stock_cost_30d, sa.avg_stock_retail_30d, sa.avg_stock_gross_30d,
|
||||||
sa.received_qty_30d, sa.received_cost_30d,
|
sa.received_qty_30d, sa.received_cost_30d,
|
||||||
-- Use total counts for lifetime values to ensure we have data even with limited history
|
-- Use total_sold from products table as the source of truth for lifetime sales
|
||||||
COALESCE(sa.total_units_sold, sa.lifetime_sales) AS lifetime_sales,
|
-- This includes all historical data from the production database
|
||||||
COALESCE(sa.total_net_revenue, sa.lifetime_revenue) AS lifetime_revenue,
|
ci.historical_total_sold AS lifetime_sales,
|
||||||
|
COALESCE(
|
||||||
|
-- Option 1: Use 30-day average price if available
|
||||||
|
CASE WHEN sa.sales_30d > 0 THEN
|
||||||
|
ci.historical_total_sold * (sa.revenue_30d / NULLIF(sa.sales_30d, 0))
|
||||||
|
ELSE NULL END,
|
||||||
|
-- Option 2: Try 365-day average price if available
|
||||||
|
CASE WHEN sa.sales_365d > 0 THEN
|
||||||
|
ci.historical_total_sold * (sa.revenue_365d / NULLIF(sa.sales_365d, 0))
|
||||||
|
ELSE NULL END,
|
||||||
|
-- Option 3: Use current price as a reasonable estimate
|
||||||
|
ci.historical_total_sold * ci.current_price,
|
||||||
|
-- Option 4: Use regular price if current price might be zero
|
||||||
|
ci.historical_total_sold * ci.current_regular_price,
|
||||||
|
-- Final fallback: Use accumulated revenue (this is less accurate for old products)
|
||||||
|
sa.total_net_revenue
|
||||||
|
) AS lifetime_revenue,
|
||||||
fpm.first_7_days_sales, fpm.first_7_days_revenue, fpm.first_30_days_sales, fpm.first_30_days_revenue,
|
fpm.first_7_days_sales, fpm.first_7_days_revenue, fpm.first_30_days_sales, fpm.first_30_days_revenue,
|
||||||
fpm.first_60_days_sales, fpm.first_60_days_revenue, fpm.first_90_days_sales, fpm.first_90_days_revenue,
|
fpm.first_60_days_sales, fpm.first_60_days_revenue, fpm.first_90_days_sales, fpm.first_90_days_revenue,
|
||||||
|
|
||||||
|
|||||||
Reference in New Issue
Block a user