Optimize order import with improved tax info retrieval and performance
This commit is contained in:
@@ -10,8 +10,8 @@ const importPurchaseOrders = require('./import/purchase-orders');
|
|||||||
dotenv.config({ path: path.join(__dirname, "../.env") });
|
dotenv.config({ path: path.join(__dirname, "../.env") });
|
||||||
|
|
||||||
// Constants to control which imports run
|
// Constants to control which imports run
|
||||||
const IMPORT_CATEGORIES = true;
|
const IMPORT_CATEGORIES = false;
|
||||||
const IMPORT_PRODUCTS = true;
|
const IMPORT_PRODUCTS = false;
|
||||||
const IMPORT_ORDERS = true;
|
const IMPORT_ORDERS = true;
|
||||||
const IMPORT_PURCHASE_ORDERS = true;
|
const IMPORT_PURCHASE_ORDERS = true;
|
||||||
|
|
||||||
|
|||||||
@@ -52,10 +52,11 @@ async function importOrders(prodConnection, localConnection) {
|
|||||||
let processed = 0;
|
let processed = 0;
|
||||||
|
|
||||||
// Process in batches
|
// Process in batches
|
||||||
const batchSize = 1000;
|
const batchSize = 20000; // Increased from 1000 since order records are small
|
||||||
let offset = 0;
|
let offset = 0;
|
||||||
|
|
||||||
while (offset < total) {
|
while (offset < total) {
|
||||||
|
// First get orders without tax info
|
||||||
const [orders] = await prodConnection.query(`
|
const [orders] = await prodConnection.query(`
|
||||||
SELECT
|
SELECT
|
||||||
oi.order_id as order_number,
|
oi.order_id as order_number,
|
||||||
@@ -65,19 +66,7 @@ async function importOrders(prodConnection, localConnection) {
|
|||||||
oi.prod_price_reg as price,
|
oi.prod_price_reg as price,
|
||||||
oi.qty_ordered as quantity,
|
oi.qty_ordered as quantity,
|
||||||
(oi.prod_price_reg - oi.prod_price) as discount,
|
(oi.prod_price_reg - oi.prod_price) as discount,
|
||||||
(
|
0 as tax,
|
||||||
SELECT
|
|
||||||
otp.item_taxes_to_collect
|
|
||||||
FROM
|
|
||||||
order_tax_info oti
|
|
||||||
JOIN order_tax_info_products otp ON oti.taxinfo_id = otp.taxinfo_id
|
|
||||||
WHERE
|
|
||||||
oti.order_id = o.order_id
|
|
||||||
AND otp.pid = oi.prod_pid
|
|
||||||
ORDER BY
|
|
||||||
oti.stamp DESC
|
|
||||||
LIMIT 1
|
|
||||||
) as tax,
|
|
||||||
0 as tax_included,
|
0 as tax_included,
|
||||||
ROUND(
|
ROUND(
|
||||||
((o.summary_shipping - COALESCE(o.summary_discount_shipping, 0)) *
|
((o.summary_shipping - COALESCE(o.summary_discount_shipping, 0)) *
|
||||||
@@ -88,7 +77,9 @@ async function importOrders(prodConnection, localConnection) {
|
|||||||
'pending' as status,
|
'pending' as status,
|
||||||
CASE WHEN o.order_status = 15 THEN 1 ELSE 0 END as canceled
|
CASE WHEN o.order_status = 15 THEN 1 ELSE 0 END as canceled
|
||||||
FROM order_items oi
|
FROM order_items oi
|
||||||
JOIN _order o ON oi.order_id = o.order_id
|
FORCE INDEX (PRIMARY)
|
||||||
|
JOIN _order o USE INDEX (date_placed_onlydate, idx_status)
|
||||||
|
ON oi.order_id = o.order_id
|
||||||
WHERE o.order_status >= 15
|
WHERE o.order_status >= 15
|
||||||
AND o.date_placed_onlydate >= DATE_SUB(CURRENT_DATE, INTERVAL 5 YEAR)
|
AND o.date_placed_onlydate >= DATE_SUB(CURRENT_DATE, INTERVAL 5 YEAR)
|
||||||
AND (o.date_placed_onlydate > ?
|
AND (o.date_placed_onlydate > ?
|
||||||
@@ -96,6 +87,37 @@ async function importOrders(prodConnection, localConnection) {
|
|||||||
LIMIT ? OFFSET ?
|
LIMIT ? OFFSET ?
|
||||||
`, [lastSyncTime, lastSyncTime, batchSize, offset]);
|
`, [lastSyncTime, lastSyncTime, batchSize, offset]);
|
||||||
|
|
||||||
|
// Then get tax info for these orders
|
||||||
|
if (orders.length > 0) {
|
||||||
|
const orderIds = [...new Set(orders.map(o => o.order_number))];
|
||||||
|
const [taxInfo] = await prodConnection.query(`
|
||||||
|
SELECT oti.order_id, otp.pid, otp.item_taxes_to_collect
|
||||||
|
FROM (
|
||||||
|
SELECT order_id, MAX(stamp) as latest_stamp
|
||||||
|
FROM order_tax_info USE INDEX (order_id, stamp)
|
||||||
|
WHERE order_id IN (?)
|
||||||
|
GROUP BY order_id
|
||||||
|
) latest
|
||||||
|
JOIN order_tax_info oti USE INDEX (order_id, stamp)
|
||||||
|
ON oti.order_id = latest.order_id
|
||||||
|
AND oti.stamp = latest.latest_stamp
|
||||||
|
JOIN order_tax_info_products otp FORCE INDEX (PRIMARY)
|
||||||
|
ON oti.taxinfo_id = otp.taxinfo_id
|
||||||
|
`, [orderIds]);
|
||||||
|
|
||||||
|
// Create a map for quick tax lookup
|
||||||
|
const taxMap = new Map();
|
||||||
|
taxInfo.forEach(t => {
|
||||||
|
taxMap.set(`${t.order_id}-${t.pid}`, t.item_taxes_to_collect);
|
||||||
|
});
|
||||||
|
|
||||||
|
// Add tax info to orders
|
||||||
|
orders.forEach(order => {
|
||||||
|
const taxKey = `${order.order_number}-${order.pid}`;
|
||||||
|
order.tax = taxMap.get(taxKey) || 0;
|
||||||
|
});
|
||||||
|
}
|
||||||
|
|
||||||
// Check if all products exist before inserting orders
|
// Check if all products exist before inserting orders
|
||||||
const orderProductPids = [...new Set(orders.map((o) => o.pid))];
|
const orderProductPids = [...new Set(orders.map((o) => o.pid))];
|
||||||
const [existingProducts] = await localConnection.query(
|
const [existingProducts] = await localConnection.query(
|
||||||
@@ -176,19 +198,7 @@ async function importOrders(prodConnection, localConnection) {
|
|||||||
oi.prod_price_reg as price,
|
oi.prod_price_reg as price,
|
||||||
oi.qty_ordered as quantity,
|
oi.qty_ordered as quantity,
|
||||||
(oi.prod_price_reg - oi.prod_price) as discount,
|
(oi.prod_price_reg - oi.prod_price) as discount,
|
||||||
(
|
0 as tax,
|
||||||
SELECT
|
|
||||||
otp.item_taxes_to_collect
|
|
||||||
FROM
|
|
||||||
order_tax_info oti
|
|
||||||
JOIN order_tax_info_products otp ON oti.taxinfo_id = otp.taxinfo_id
|
|
||||||
WHERE
|
|
||||||
oti.order_id = o.order_id
|
|
||||||
AND otp.pid = oi.prod_pid
|
|
||||||
ORDER BY
|
|
||||||
oti.stamp DESC
|
|
||||||
LIMIT 1
|
|
||||||
) as tax,
|
|
||||||
0 as tax_included,
|
0 as tax_included,
|
||||||
ROUND(
|
ROUND(
|
||||||
((o.summary_shipping - COALESCE(o.summary_discount_shipping, 0)) *
|
((o.summary_shipping - COALESCE(o.summary_discount_shipping, 0)) *
|
||||||
@@ -203,6 +213,36 @@ async function importOrders(prodConnection, localConnection) {
|
|||||||
WHERE oi.order_id IN (?)
|
WHERE oi.order_id IN (?)
|
||||||
`, [[...skippedOrders]]);
|
`, [[...skippedOrders]]);
|
||||||
|
|
||||||
|
if (retryOrders.length > 0) {
|
||||||
|
const retryOrderIds = [...new Set(retryOrders.map(o => o.order_number))];
|
||||||
|
const [retryTaxInfo] = await prodConnection.query(`
|
||||||
|
SELECT oti.order_id, otp.pid, otp.item_taxes_to_collect
|
||||||
|
FROM (
|
||||||
|
SELECT order_id, MAX(stamp) as latest_stamp
|
||||||
|
FROM order_tax_info USE INDEX (order_id, stamp)
|
||||||
|
WHERE order_id IN (?)
|
||||||
|
GROUP BY order_id
|
||||||
|
) latest
|
||||||
|
JOIN order_tax_info oti USE INDEX (order_id, stamp)
|
||||||
|
ON oti.order_id = latest.order_id
|
||||||
|
AND oti.stamp = latest.latest_stamp
|
||||||
|
JOIN order_tax_info_products otp FORCE INDEX (PRIMARY)
|
||||||
|
ON oti.taxinfo_id = otp.taxinfo_id
|
||||||
|
`, [retryOrderIds]);
|
||||||
|
|
||||||
|
// Create a map for quick tax lookup
|
||||||
|
const taxMap = new Map();
|
||||||
|
retryTaxInfo.forEach(t => {
|
||||||
|
taxMap.set(`${t.order_id}-${t.pid}`, t.item_taxes_to_collect);
|
||||||
|
});
|
||||||
|
|
||||||
|
// Add tax info to orders
|
||||||
|
retryOrders.forEach(order => {
|
||||||
|
const taxKey = `${order.order_number}-${order.pid}`;
|
||||||
|
order.tax = taxMap.get(taxKey) || 0;
|
||||||
|
});
|
||||||
|
}
|
||||||
|
|
||||||
const placeholders = retryOrders
|
const placeholders = retryOrders
|
||||||
.map(() => `(${Array(columnNames.length).fill("?").join(",")})`)
|
.map(() => `(${Array(columnNames.length).fill("?").join(",")})`)
|
||||||
.join(",");
|
.join(",");
|
||||||
|
|||||||
Reference in New Issue
Block a user