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_taxes;
|
||||
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 (
|
||||
order_id INTEGER NOT NULL,
|
||||
@@ -144,6 +146,21 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
|
||||
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 (
|
||||
order_id 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_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_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();
|
||||
} catch (error) {
|
||||
@@ -296,38 +316,97 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
|
||||
};
|
||||
|
||||
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(`
|
||||
SELECT order_id, pid, SUM(amount) as discount
|
||||
SELECT order_id, pid, discount_id, amount
|
||||
FROM order_discount_items
|
||||
WHERE order_id IN (?)
|
||||
GROUP BY order_id, pid
|
||||
`, [batchIds]);
|
||||
|
||||
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();
|
||||
try {
|
||||
for (let j = 0; j < discounts.length; j += PG_BATCH_SIZE) {
|
||||
const subBatch = discounts.slice(j, j + PG_BATCH_SIZE);
|
||||
for (let j = 0; j < uniqueDiscounts.length; j += PG_BATCH_SIZE) {
|
||||
const subBatch = uniqueDiscounts.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})`
|
||||
`($${idx * 4 + 1}, $${idx * 4 + 2}, $${idx * 4 + 3}, $${idx * 4 + 4})`
|
||||
).join(",");
|
||||
|
||||
const values = subBatch.flatMap(d => [
|
||||
d.order_id,
|
||||
d.pid,
|
||||
d.discount || 0
|
||||
d.discount_id,
|
||||
d.amount || 0
|
||||
]);
|
||||
|
||||
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}
|
||||
ON CONFLICT (order_id, pid) DO UPDATE SET
|
||||
discount = EXCLUDED.discount
|
||||
ON CONFLICT (order_id, pid, discount_id) DO UPDATE SET
|
||||
amount = EXCLUDED.amount
|
||||
`, 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();
|
||||
} catch (error) {
|
||||
await localConnection.rollback();
|
||||
@@ -485,11 +564,16 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
|
||||
SELECT
|
||||
oi.order_id,
|
||||
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(oc.costeach, oi.price * 0.5) as costeach
|
||||
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_costs oc ON oi.order_id = oc.order_id AND oi.pid = oc.pid
|
||||
WHERE oi.order_id = ANY($1)
|
||||
@@ -513,8 +597,8 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
|
||||
ELSE 0
|
||||
END
|
||||
+
|
||||
-- Part 3: Specific Promo Code Discount (if applicable)
|
||||
COALESCE(ot.promo_discount, 0)
|
||||
-- Part 3: Specific Item-Level Discount (only if parent discount affected subtotal)
|
||||
COALESCE(ot.promo_discount_sum, 0)
|
||||
)::NUMERIC(14, 4) as discount,
|
||||
COALESCE(ot.total_tax, 0)::NUMERIC(14, 4) as tax,
|
||||
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_taxes;
|
||||
DROP TABLE IF EXISTS temp_order_costs;
|
||||
DROP TABLE IF EXISTS temp_main_discounts;
|
||||
DROP TABLE IF EXISTS temp_item_discounts;
|
||||
`);
|
||||
|
||||
// Commit final transaction
|
||||
|
||||
Reference in New Issue
Block a user