- Update import-from-prod.js to support granular incremental updates for different import types - Modify orders.js to handle complex order data retrieval with better performance and error tracking - Add support for incremental updates in products.js import function - Improve logging and progress tracking for import processes
355 lines
13 KiB
JavaScript
355 lines
13 KiB
JavaScript
const { outputProgress, formatElapsedTime, estimateRemaining, calculateRate } = require('../metrics/utils/progress');
|
|
const { importMissingProducts } = require('./products');
|
|
|
|
/**
|
|
* Imports orders from a production MySQL database to a local MySQL database.
|
|
* It can run in two modes:
|
|
* 1. Incremental update mode (default): Only fetch orders that have changed since the last sync time.
|
|
* 2. Full update mode: Fetch all eligible orders within the last 5 years regardless of timestamp.
|
|
*
|
|
* @param {object} prodConnection - A MySQL connection to production DB (MySQL 5.7).
|
|
* @param {object} localConnection - A MySQL connection to local DB (MySQL 8.0).
|
|
* @param {boolean} incrementalUpdate - Set to false for a full sync; true for incremental.
|
|
*
|
|
* @returns {object} Information about the sync operation.
|
|
*/
|
|
async function importOrders(prodConnection, localConnection, incrementalUpdate = true) {
|
|
const startTime = Date.now();
|
|
const skippedOrders = new Set();
|
|
const missingProducts = new Set();
|
|
|
|
try {
|
|
// Get column names from the local table
|
|
const [columns] = await localConnection.query(`
|
|
SELECT COLUMN_NAME
|
|
FROM INFORMATION_SCHEMA.COLUMNS
|
|
WHERE TABLE_NAME = 'orders'
|
|
ORDER BY ORDINAL_POSITION
|
|
`);
|
|
const columnNames = columns.map(col => col.COLUMN_NAME);
|
|
|
|
// Get last sync info
|
|
const [syncInfo] = await localConnection.query(
|
|
"SELECT last_sync_timestamp FROM sync_status WHERE table_name = 'orders'"
|
|
);
|
|
const lastSyncTime = syncInfo?.[0]?.last_sync_timestamp || '1970-01-01';
|
|
|
|
// Count the total number of orders to be imported
|
|
const [countResults] = await prodConnection.query(`
|
|
SELECT
|
|
COUNT(DISTINCT oi.order_id, oi.prod_pid) as total_all,
|
|
SUM(CASE
|
|
WHEN o.stamp > ? OR o.date_placed > ? OR o.date_shipped > ? OR oi.stamp > ?
|
|
THEN 1 ELSE 0
|
|
END) as total_incremental
|
|
FROM order_items oi
|
|
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 5 YEAR)
|
|
AND o.date_placed_onlydate IS NOT NULL
|
|
`, [lastSyncTime, lastSyncTime, lastSyncTime, lastSyncTime]);
|
|
|
|
console.log('Count details:', {
|
|
total_all: countResults[0].total_all,
|
|
total_incremental: countResults[0].total_incremental,
|
|
lastSyncTime,
|
|
incrementalUpdate
|
|
});
|
|
|
|
const totalOrders = incrementalUpdate ? countResults[0].total_incremental : countResults[0].total_all;
|
|
|
|
outputProgress({
|
|
status: "running",
|
|
operation: "Orders import",
|
|
message: `Starting ${incrementalUpdate ? 'incremental' : 'full'} import of ${totalOrders} orders`,
|
|
current: 0,
|
|
total: totalOrders
|
|
});
|
|
|
|
// Fetch orders in batches
|
|
const batchSize = 5000;
|
|
let offset = 0;
|
|
let importedCount = 0;
|
|
let lastProgressUpdate = Date.now();
|
|
|
|
while (offset < totalOrders) {
|
|
// First get the base order data
|
|
const [prodOrders] = await prodConnection.query(`
|
|
SELECT
|
|
oi.order_id as order_number,
|
|
oi.prod_pid as pid,
|
|
oi.prod_itemnumber as SKU,
|
|
o.date_placed_onlydate as date,
|
|
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,
|
|
o.order_cid as customer,
|
|
CONCAT(COALESCE(u.firstname, ''), ' ', COALESCE(u.lastname, '')) as customer_name,
|
|
o.order_status as status,
|
|
CASE WHEN o.date_cancelled != '0000-00-00 00:00:00' THEN 1 ELSE 0 END as canceled
|
|
FROM order_items oi
|
|
JOIN _order o ON oi.order_id = o.order_id
|
|
LEFT JOIN users u ON o.order_cid = u.cid
|
|
WHERE o.order_status >= 15
|
|
AND o.date_placed_onlydate >= DATE_SUB(CURRENT_DATE, INTERVAL 5 YEAR)
|
|
AND o.date_placed_onlydate IS NOT NULL
|
|
${incrementalUpdate ? `
|
|
AND (
|
|
o.stamp > ?
|
|
OR o.date_placed > ?
|
|
OR o.date_shipped > ?
|
|
OR oi.stamp > ?
|
|
)
|
|
` : ''}
|
|
ORDER BY oi.order_id, oi.prod_pid
|
|
LIMIT ? OFFSET ?
|
|
`, incrementalUpdate ?
|
|
[lastSyncTime, lastSyncTime, lastSyncTime, lastSyncTime, batchSize, offset] :
|
|
[batchSize, offset]
|
|
);
|
|
|
|
if (prodOrders.length === 0) break;
|
|
|
|
// Get order numbers for this batch
|
|
const orderNumbers = [...new Set(prodOrders.map(o => o.order_number))];
|
|
const orderPids = prodOrders.map(o => o.pid);
|
|
|
|
// Get promotional discounts in a separate query
|
|
const [promoDiscounts] = await prodConnection.query(`
|
|
SELECT order_id, pid, amount
|
|
FROM order_discount_items
|
|
WHERE order_id IN (?)
|
|
`, [orderNumbers]);
|
|
|
|
// Create a map for quick discount lookups
|
|
const discountMap = new Map();
|
|
promoDiscounts.forEach(d => {
|
|
const key = `${d.order_id}-${d.pid}`;
|
|
discountMap.set(key, d.amount || 0);
|
|
});
|
|
|
|
// Get tax information in a separate query
|
|
const [taxInfo] = await prodConnection.query(`
|
|
SELECT oti.order_id, otip.pid, otip.item_taxes_to_collect
|
|
FROM order_tax_info oti
|
|
JOIN order_tax_info_products otip ON oti.taxinfo_id = otip.taxinfo_id
|
|
WHERE oti.order_id IN (?)
|
|
AND (oti.order_id, oti.stamp) IN (
|
|
SELECT order_id, MAX(stamp)
|
|
FROM order_tax_info
|
|
WHERE order_id IN (?)
|
|
GROUP BY order_id
|
|
)
|
|
`, [orderNumbers, orderNumbers]);
|
|
|
|
// Create a map for quick tax lookups
|
|
const taxMap = new Map();
|
|
taxInfo.forEach(t => {
|
|
const key = `${t.order_id}-${t.pid}`;
|
|
taxMap.set(key, t.item_taxes_to_collect || 0);
|
|
});
|
|
|
|
// Check for missing products
|
|
const [existingProducts] = await localConnection.query(
|
|
"SELECT pid FROM products WHERE pid IN (?)",
|
|
[orderPids]
|
|
);
|
|
const existingPids = new Set(existingProducts.map(p => p.pid));
|
|
|
|
// Track missing products and filter orders
|
|
const validOrders = prodOrders.filter(order => {
|
|
if (!order.date) return false;
|
|
if (!existingPids.has(order.pid)) {
|
|
missingProducts.add(order.pid);
|
|
skippedOrders.add(order.order_number);
|
|
return false;
|
|
}
|
|
return true;
|
|
});
|
|
|
|
// Prepare values for insertion
|
|
const orderValues = validOrders.map(order => {
|
|
const orderKey = `${order.order_number}-${order.pid}`;
|
|
const orderData = {
|
|
id: order.order_number,
|
|
order_number: order.order_number,
|
|
pid: order.pid,
|
|
SKU: order.SKU,
|
|
date: order.date,
|
|
price: order.price,
|
|
quantity: order.quantity,
|
|
discount: Number(order.base_discount || 0) + Number(discountMap.get(orderKey) || 0),
|
|
tax: Number(taxMap.get(orderKey) || 0),
|
|
tax_included: 0,
|
|
shipping: 0,
|
|
customer: order.customer,
|
|
customer_name: order.customer_name || '',
|
|
status: order.status,
|
|
canceled: order.canceled,
|
|
};
|
|
|
|
return columnNames.map(colName => orderData[colName] !== undefined ? orderData[colName] : null);
|
|
});
|
|
|
|
// Execute the insert
|
|
if (orderValues.length > 0) {
|
|
const placeholders = validOrders.map(() => `(${columnNames.map(() => "?").join(", ")})`).join(",");
|
|
const insertQuery = `
|
|
INSERT INTO orders (${columnNames.join(", ")})
|
|
VALUES ${placeholders}
|
|
ON DUPLICATE KEY UPDATE
|
|
${columnNames.map(col => `${col} = VALUES(${col})`).join(", ")}
|
|
`;
|
|
|
|
await localConnection.query(insertQuery, orderValues.flat());
|
|
}
|
|
|
|
importedCount += validOrders.length;
|
|
offset += batchSize;
|
|
|
|
// Update progress every second
|
|
const now = Date.now();
|
|
if (now - lastProgressUpdate >= 1000) {
|
|
outputProgress({
|
|
status: "running",
|
|
operation: "Orders import",
|
|
message: `Imported ${importedCount} of ${totalOrders} orders`,
|
|
current: importedCount,
|
|
total: totalOrders,
|
|
elapsed: formatElapsedTime((now - startTime) / 1000),
|
|
remaining: estimateRemaining(startTime, importedCount, totalOrders),
|
|
rate: calculateRate(startTime, importedCount)
|
|
});
|
|
lastProgressUpdate = now;
|
|
}
|
|
}
|
|
|
|
// Import missing products if any
|
|
if (missingProducts.size > 0) {
|
|
await importMissingProducts(prodConnection, localConnection, Array.from(missingProducts));
|
|
|
|
// Retry skipped orders after importing products
|
|
if (skippedOrders.size > 0) {
|
|
outputProgress({
|
|
status: "running",
|
|
operation: "Orders import",
|
|
message: `Retrying import of ${skippedOrders.size} orders with previously missing products`
|
|
});
|
|
|
|
const [skippedProdOrders] = await prodConnection.query(`
|
|
SELECT
|
|
o.order_id,
|
|
CASE
|
|
WHEN o.date_placed = '0000-00-00 00:00:00' OR o.date_placed IS NULL THEN o.stamp
|
|
ELSE o.date_placed
|
|
END as date,
|
|
o.order_cid,
|
|
o.bill_firstname,
|
|
o.bill_lastname,
|
|
o.order_email,
|
|
o.order_status,
|
|
o.date_shipped,
|
|
o.date_cancelled,
|
|
oi.prod_pid,
|
|
oi.prod_itemnumber,
|
|
oi.prod_price,
|
|
oi.qty_ordered,
|
|
oi.qty_back,
|
|
oi.qty_placed,
|
|
oi.qty_placed_2,
|
|
oi.discounted,
|
|
oi.summary_cogs,
|
|
oi.summary_profit,
|
|
oi.summary_orderdate,
|
|
oi.summary_paiddate,
|
|
oi.date_added,
|
|
oi.stamp
|
|
FROM order_items oi
|
|
JOIN _order o ON oi.order_id = o.order_id
|
|
WHERE o.order_id IN (?)
|
|
`, [Array.from(skippedOrders)]);
|
|
|
|
// Prepare values for insertion
|
|
const skippedOrderValues = skippedProdOrders.flatMap(order => {
|
|
if (!order.date) {
|
|
console.log(`Warning: Skipped order ${order.order_id} has null date:`, JSON.stringify(order, null, 2));
|
|
return [];
|
|
}
|
|
|
|
const canceled = order.date_cancelled !== '0000-00-00 00:00:00' ? 1 : 0;
|
|
const customerName = `${order.bill_firstname} ${order.bill_lastname}`;
|
|
|
|
// Create an object with keys based on column names
|
|
const orderData = {
|
|
id: order.order_id,
|
|
order_number: order.order_id,
|
|
pid: order.prod_pid,
|
|
SKU: order.prod_itemnumber,
|
|
date: order.date ? (
|
|
order.date instanceof Date ?
|
|
order.date.toJSON()?.slice(0,10) || null :
|
|
(typeof order.date === 'string' ? order.date.split(' ')[0] : null)
|
|
) : null,
|
|
price: order.prod_price,
|
|
quantity: order.qty_ordered,
|
|
discount: order.discounted,
|
|
tax: 0, // Placeholder, will be calculated later
|
|
tax_included: 0, // Placeholder, will be calculated later
|
|
shipping: 0, // Placeholder, will be calculated later
|
|
customer: order.order_email,
|
|
customer_name: customerName,
|
|
status: order.order_status,
|
|
canceled: canceled,
|
|
};
|
|
|
|
// Map column names to values, handling missing columns
|
|
return [columnNames.map(colName => orderData[colName] !== undefined ? orderData[colName] : null)];
|
|
});
|
|
|
|
// Construct the insert query dynamically
|
|
const skippedPlaceholders = skippedProdOrders.map(() => `(${columnNames.map(() => "?").join(", ")})`).join(",");
|
|
const skippedInsertQuery = `
|
|
INSERT INTO orders (${columnNames.join(", ")})
|
|
VALUES ${skippedPlaceholders}
|
|
ON DUPLICATE KEY UPDATE
|
|
${columnNames.map(col => `${col} = VALUES(${col})`).join(", ")}
|
|
`;
|
|
|
|
// Execute the insert query
|
|
if (skippedOrderValues.length > 0) {
|
|
await localConnection.query(skippedInsertQuery, skippedOrderValues.flat());
|
|
}
|
|
|
|
importedCount += skippedProdOrders.length;
|
|
|
|
outputProgress({
|
|
status: "running",
|
|
operation: "Orders import",
|
|
message: `Successfully imported ${skippedProdOrders.length} previously skipped orders`,
|
|
});
|
|
}
|
|
}
|
|
|
|
// Update sync status
|
|
await localConnection.query(`
|
|
INSERT INTO sync_status (table_name, last_sync_timestamp)
|
|
VALUES ('orders', NOW())
|
|
ON DUPLICATE KEY UPDATE last_sync_timestamp = NOW()
|
|
`);
|
|
|
|
return {
|
|
status: "complete",
|
|
totalImported: importedCount,
|
|
totalSkipped: skippedOrders.size,
|
|
missingProducts: missingProducts.size,
|
|
incrementalUpdate,
|
|
lastSyncTime
|
|
};
|
|
} catch (error) {
|
|
console.error("Error during orders import:", error);
|
|
throw error;
|
|
}
|
|
}
|
|
|
|
module.exports = importOrders;
|