Finish up import script incremental and reliability updates
This commit is contained in:
@@ -21,6 +21,46 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
|
||||
let recordsUpdated = 0;
|
||||
|
||||
try {
|
||||
// Insert temporary table creation queries
|
||||
await localConnection.query(`
|
||||
CREATE TABLE IF NOT EXISTS temp_order_items (
|
||||
order_id INT UNSIGNED NOT NULL,
|
||||
pid INT UNSIGNED NOT NULL,
|
||||
SKU VARCHAR(50) NOT NULL,
|
||||
price DECIMAL(10,2) NOT NULL,
|
||||
quantity INT NOT NULL,
|
||||
base_discount DECIMAL(10,2) DEFAULT 0,
|
||||
PRIMARY KEY (order_id, pid)
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
|
||||
`);
|
||||
await localConnection.query(`
|
||||
CREATE TABLE IF NOT EXISTS temp_order_meta (
|
||||
order_id INT UNSIGNED NOT NULL,
|
||||
date DATE NOT NULL,
|
||||
customer VARCHAR(100) NOT NULL,
|
||||
customer_name VARCHAR(150) NOT NULL,
|
||||
status INT,
|
||||
canceled TINYINT(1),
|
||||
PRIMARY KEY (order_id)
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
|
||||
`);
|
||||
await localConnection.query(`
|
||||
CREATE TABLE IF NOT EXISTS temp_order_discounts (
|
||||
order_id INT UNSIGNED NOT NULL,
|
||||
pid INT UNSIGNED NOT NULL,
|
||||
discount DECIMAL(10,2) NOT NULL,
|
||||
PRIMARY KEY (order_id, pid)
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
|
||||
`);
|
||||
await localConnection.query(`
|
||||
CREATE TABLE IF NOT EXISTS temp_order_taxes (
|
||||
order_id INT UNSIGNED NOT NULL,
|
||||
pid INT UNSIGNED NOT NULL,
|
||||
tax DECIMAL(10,2) NOT NULL,
|
||||
PRIMARY KEY (order_id, pid)
|
||||
) ENGINE=InnoDB DEFAULT CHARSET=utf8;
|
||||
`);
|
||||
|
||||
// Get column names from the local table
|
||||
const [columns] = await localConnection.query(`
|
||||
SELECT COLUMN_NAME
|
||||
@@ -36,52 +76,11 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
|
||||
);
|
||||
const lastSyncTime = syncInfo?.[0]?.last_sync_timestamp || '1970-01-01';
|
||||
|
||||
// Create temporary tables for staging data
|
||||
await localConnection.query(`
|
||||
CREATE TEMPORARY TABLE temp_order_items (
|
||||
order_id INT UNSIGNED,
|
||||
pid INT UNSIGNED,
|
||||
SKU VARCHAR(50),
|
||||
price DECIMAL(10,3),
|
||||
quantity INT,
|
||||
base_discount DECIMAL(10,3),
|
||||
PRIMARY KEY (order_id, pid)
|
||||
) ENGINE=InnoDB;
|
||||
console.log('Orders: Using last sync time:', lastSyncTime);
|
||||
|
||||
CREATE TEMPORARY TABLE temp_order_meta (
|
||||
order_id INT UNSIGNED PRIMARY KEY,
|
||||
date DATE,
|
||||
customer INT UNSIGNED,
|
||||
customer_name VARCHAR(100),
|
||||
status TINYINT UNSIGNED,
|
||||
canceled TINYINT UNSIGNED
|
||||
) ENGINE=InnoDB;
|
||||
|
||||
CREATE TEMPORARY TABLE temp_order_discounts (
|
||||
order_id INT UNSIGNED,
|
||||
pid INT UNSIGNED,
|
||||
discount DECIMAL(10,3),
|
||||
PRIMARY KEY (order_id, pid)
|
||||
) ENGINE=InnoDB;
|
||||
|
||||
CREATE TEMPORARY TABLE temp_order_taxes (
|
||||
order_id INT UNSIGNED,
|
||||
pid INT UNSIGNED,
|
||||
tax DECIMAL(10,3),
|
||||
PRIMARY KEY (order_id, pid)
|
||||
) ENGINE=InnoDB;
|
||||
`);
|
||||
|
||||
// Get base order items first
|
||||
console.log('Last sync time:', lastSyncTime);
|
||||
const [orderItems] = await prodConnection.query(`
|
||||
SELECT
|
||||
oi.order_id,
|
||||
oi.prod_pid as pid,
|
||||
oi.prod_itemnumber as SKU,
|
||||
oi.prod_price as price,
|
||||
oi.qty_ordered as quantity,
|
||||
COALESCE(oi.prod_price_reg - oi.prod_price, 0) * oi.qty_ordered as base_discount
|
||||
// First get all relevant order items with basic info
|
||||
const [[{ total }]] = await prodConnection.query(`
|
||||
SELECT COUNT(*) as total
|
||||
FROM order_items oi
|
||||
USE INDEX (PRIMARY)
|
||||
JOIN _order o ON oi.order_id = o.order_id
|
||||
@@ -92,11 +91,61 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
|
||||
AND (
|
||||
o.stamp > ?
|
||||
OR oi.stamp > ?
|
||||
OR EXISTS (
|
||||
SELECT 1 FROM order_discount_items odi
|
||||
WHERE odi.order_id = o.order_id
|
||||
AND odi.pid = oi.prod_pid
|
||||
)
|
||||
OR EXISTS (
|
||||
SELECT 1 FROM order_tax_info oti
|
||||
JOIN order_tax_info_products otip ON oti.taxinfo_id = otip.taxinfo_id
|
||||
WHERE oti.order_id = o.order_id
|
||||
AND otip.pid = oi.prod_pid
|
||||
AND oti.stamp > ?
|
||||
)
|
||||
)
|
||||
` : ''}
|
||||
`, incrementalUpdate ? [lastSyncTime, lastSyncTime] : []);
|
||||
`, incrementalUpdate ? [lastSyncTime, lastSyncTime, lastSyncTime] : []);
|
||||
|
||||
console.log('Found', orderItems.length, 'orders to process');
|
||||
console.log('Orders: Found changes:', total);
|
||||
|
||||
// Get order items in batches
|
||||
const [orderItems] = await prodConnection.query(`
|
||||
SELECT
|
||||
oi.order_id,
|
||||
oi.prod_pid as pid,
|
||||
oi.prod_itemnumber as SKU,
|
||||
oi.prod_price as price,
|
||||
oi.qty_ordered as quantity,
|
||||
COALESCE(oi.prod_price_reg - oi.prod_price, 0) * oi.qty_ordered as base_discount,
|
||||
oi.stamp as last_modified
|
||||
FROM order_items oi
|
||||
USE INDEX (PRIMARY)
|
||||
JOIN _order o ON oi.order_id = o.order_id
|
||||
WHERE o.order_status >= 15
|
||||
AND o.date_placed_onlydate >= DATE_SUB(CURRENT_DATE, INTERVAL ${incrementalUpdate ? '1' : '5'} YEAR)
|
||||
AND o.date_placed_onlydate IS NOT NULL
|
||||
${incrementalUpdate ? `
|
||||
AND (
|
||||
o.stamp > ?
|
||||
OR oi.stamp > ?
|
||||
OR EXISTS (
|
||||
SELECT 1 FROM order_discount_items odi
|
||||
WHERE odi.order_id = o.order_id
|
||||
AND odi.pid = oi.prod_pid
|
||||
)
|
||||
OR EXISTS (
|
||||
SELECT 1 FROM order_tax_info oti
|
||||
JOIN order_tax_info_products otip ON oti.taxinfo_id = otip.taxinfo_id
|
||||
WHERE oti.order_id = o.order_id
|
||||
AND otip.pid = oi.prod_pid
|
||||
AND oti.stamp > ?
|
||||
)
|
||||
)
|
||||
` : ''}
|
||||
`, incrementalUpdate ? [lastSyncTime, lastSyncTime, lastSyncTime] : []);
|
||||
|
||||
console.log('Orders: Processing', orderItems.length, 'order items');
|
||||
|
||||
const totalOrders = orderItems.length;
|
||||
let processed = 0;
|
||||
@@ -280,30 +329,82 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
|
||||
const singlePlaceholder = `(${columnNames.map(() => "?").join(",")})`;
|
||||
const placeholders = Array(validOrders.length).fill(singlePlaceholder).join(",");
|
||||
|
||||
const query = `
|
||||
INSERT INTO orders (${columnNames.join(",")})
|
||||
VALUES ${placeholders}
|
||||
ON DUPLICATE KEY UPDATE
|
||||
SKU = VALUES(SKU),
|
||||
date = VALUES(date),
|
||||
price = VALUES(price),
|
||||
quantity = VALUES(quantity),
|
||||
discount = VALUES(discount),
|
||||
tax = VALUES(tax),
|
||||
tax_included = VALUES(tax_included),
|
||||
shipping = VALUES(shipping),
|
||||
customer = VALUES(customer),
|
||||
customer_name = VALUES(customer_name),
|
||||
status = VALUES(status),
|
||||
canceled = VALUES(canceled)
|
||||
`;
|
||||
// First check which orders exist and get their current values
|
||||
const [existingOrders] = await localConnection.query(
|
||||
`SELECT ${columnNames.join(',')} FROM orders WHERE (order_number, pid) IN (${validOrders.map(() => "(?,?)").join(",")})`,
|
||||
validOrders.flatMap(o => [o.order_number, o.pid])
|
||||
);
|
||||
const existingOrderMap = new Map(
|
||||
existingOrders.map(o => [`${o.order_number}-${o.pid}`, o])
|
||||
);
|
||||
|
||||
const result = await localConnection.query(query, values);
|
||||
// For INSERT ... ON DUPLICATE KEY UPDATE:
|
||||
// - affectedRows is 1 for each inserted row and 2 for each updated row
|
||||
// - changedRows is 1 for each row that was actually changed during update
|
||||
recordsAdded += result[0].affectedRows - (2 * result[0].changedRows); // New rows
|
||||
recordsUpdated += result[0].changedRows; // Actually changed rows
|
||||
// Split into inserts and updates
|
||||
const insertsAndUpdates = validOrders.reduce((acc, order) => {
|
||||
const key = `${order.order_number}-${order.pid}`;
|
||||
if (existingOrderMap.has(key)) {
|
||||
const existing = existingOrderMap.get(key);
|
||||
// Check if any values are different
|
||||
const hasChanges = columnNames.some(col => {
|
||||
const newVal = order[col] ?? null;
|
||||
const oldVal = existing[col] ?? null;
|
||||
// Special handling for numbers to avoid type coercion issues
|
||||
if (typeof newVal === 'number' && typeof oldVal === 'number') {
|
||||
return Math.abs(newVal - oldVal) > 0.00001; // Allow for tiny floating point differences
|
||||
}
|
||||
return newVal !== oldVal;
|
||||
});
|
||||
|
||||
if (hasChanges) {
|
||||
acc.updates.push({
|
||||
order_number: order.order_number,
|
||||
pid: order.pid,
|
||||
values: columnNames.map(col => order[col] ?? null)
|
||||
});
|
||||
} else {
|
||||
acc.inserts.push({
|
||||
order_number: order.order_number,
|
||||
pid: order.pid,
|
||||
values: columnNames.map(col => order[col] ?? null)
|
||||
});
|
||||
}
|
||||
return acc;
|
||||
|
||||
// Handle inserts
|
||||
if (insertsAndUpdates.inserts.length > 0) {
|
||||
const insertPlaceholders = Array(insertsAndUpdates.inserts.length).fill(singlePlaceholder).join(",");
|
||||
|
||||
const insertResult = await localConnection.query(`
|
||||
INSERT INTO orders (${columnNames.join(",")})
|
||||
VALUES ${insertPlaceholders}
|
||||
`, insertsAndUpdates.inserts.map(i => i.values).flat());
|
||||
|
||||
recordsAdded += insertResult[0].affectedRows;
|
||||
}
|
||||
|
||||
// Handle updates - now we know these actually have changes
|
||||
if (insertsAndUpdates.updates.length > 0) {
|
||||
const updatePlaceholders = Array(insertsAndUpdates.updates.length).fill(singlePlaceholder).join(",");
|
||||
|
||||
const updateResult = await localConnection.query(`
|
||||
INSERT INTO orders (${columnNames.join(",")})
|
||||
VALUES ${updatePlaceholders}
|
||||
ON DUPLICATE KEY UPDATE
|
||||
SKU = VALUES(SKU),
|
||||
date = VALUES(date),
|
||||
price = VALUES(price),
|
||||
quantity = VALUES(quantity),
|
||||
discount = VALUES(discount),
|
||||
tax = VALUES(tax),
|
||||
tax_included = VALUES(tax_included),
|
||||
shipping = VALUES(shipping),
|
||||
customer = VALUES(customer),
|
||||
customer_name = VALUES(customer_name),
|
||||
status = VALUES(status),
|
||||
canceled = VALUES(canceled)
|
||||
`, insertsAndUpdates.updates.map(u => u.values).flat());
|
||||
|
||||
recordsUpdated += updateResult[0].affectedRows / 2; // Each update counts as 2 in affectedRows
|
||||
}
|
||||
|
||||
importedCount += validOrders.length;
|
||||
}
|
||||
|
||||
Reference in New Issue
Block a user