const { outputProgress, formatElapsedTime, estimateRemaining, calculateRate } = require('../metrics/utils/progress'); const { importMissingProducts, setupTemporaryTables, cleanupTemporaryTables, materializeCalculations } = 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(); let recordsAdded = 0; 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 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'; console.log('Orders: Using last sync time:', lastSyncTime); // 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 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: 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; // Insert order items in batches for (let i = 0; i < orderItems.length; i += 5000) { const batch = orderItems.slice(i, Math.min(i + 5000, orderItems.length)); const placeholders = batch.map(() => "(?, ?, ?, ?, ?, ?)").join(","); const values = batch.flatMap(item => [ item.order_id, item.pid, item.SKU, item.price, item.quantity, item.base_discount ]); await localConnection.query(` INSERT INTO temp_order_items (order_id, pid, SKU, price, quantity, base_discount) VALUES ${placeholders} ON DUPLICATE KEY UPDATE SKU = VALUES(SKU), price = VALUES(price), quantity = VALUES(quantity), base_discount = VALUES(base_discount) `, values); processed += batch.length; outputProgress({ status: "running", operation: "Orders import", message: `Loading order items: ${processed} of ${totalOrders}`, current: processed, total: totalOrders }); } // Get unique order IDs const orderIds = [...new Set(orderItems.map(item => item.order_id))]; // Get order metadata in batches for (let i = 0; i < orderIds.length; i += 5000) { const batchIds = orderIds.slice(i, i + 5000); const [orders] = await prodConnection.query(` SELECT o.order_id, o.date_placed_onlydate as date, 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 o LEFT JOIN users u ON o.order_cid = u.cid WHERE o.order_id IN (?) `, [batchIds]); const placeholders = orders.map(() => "(?, ?, ?, ?, ?, ?)").join(","); const values = orders.flatMap(order => [ order.order_id, order.date, order.customer, order.customer_name, order.status, order.canceled ]); await localConnection.query(` INSERT INTO temp_order_meta VALUES ${placeholders} `, values); outputProgress({ status: "running", operation: "Orders import", message: `Loading order metadata: ${i + orders.length} of ${orderIds.length}`, current: i + orders.length, total: orderIds.length }); } // Get promotional discounts in batches for (let i = 0; i < orderIds.length; i += 5000) { const batchIds = orderIds.slice(i, i + 5000); const [discounts] = await prodConnection.query(` SELECT order_id, pid, SUM(amount) as discount FROM order_discount_items WHERE order_id IN (?) GROUP BY order_id, pid `, [batchIds]); if (discounts.length > 0) { const placeholders = discounts.map(() => "(?, ?, ?)").join(","); const values = discounts.flatMap(d => [d.order_id, d.pid, d.discount]); await localConnection.query(` INSERT INTO temp_order_discounts VALUES ${placeholders} `, values); } } // Get tax information in batches for (let i = 0; i < orderIds.length; i += 5000) { const batchIds = orderIds.slice(i, i + 5000); const [taxes] = await prodConnection.query(` SELECT DISTINCT oti.order_id, otip.pid, otip.item_taxes_to_collect as tax FROM order_tax_info oti JOIN ( SELECT order_id, MAX(stamp) as max_stamp FROM order_tax_info WHERE order_id IN (?) GROUP BY order_id ) latest ON oti.order_id = latest.order_id AND oti.stamp = latest.max_stamp JOIN order_tax_info_products otip ON oti.taxinfo_id = otip.taxinfo_id `, [batchIds]); if (taxes.length > 0) { // Remove any duplicates before inserting const uniqueTaxes = new Map(); taxes.forEach(t => { const key = `${t.order_id}-${t.pid}`; uniqueTaxes.set(key, t); }); const values = Array.from(uniqueTaxes.values()).flatMap(t => [t.order_id, t.pid, t.tax]); if (values.length > 0) { const placeholders = Array(uniqueTaxes.size).fill("(?, ?, ?)").join(","); await localConnection.query(` INSERT INTO temp_order_taxes VALUES ${placeholders} `, values); } } } // Now combine all the data and insert into orders table let importedCount = 0; // Pre-check all products at once instead of per batch const allOrderPids = [...new Set(orderItems.map(item => item.pid))]; const [existingProducts] = allOrderPids.length > 0 ? await localConnection.query( "SELECT pid FROM products WHERE pid IN (?)", [allOrderPids] ) : [[]]; const existingPids = new Set(existingProducts.map(p => p.pid)); // Process in larger batches for (let i = 0; i < orderIds.length; i += 5000) { const batchIds = orderIds.slice(i, i + 5000); // Get combined data for this batch const [orders] = await localConnection.query(` SELECT oi.order_id as order_number, oi.pid, oi.SKU, om.date, oi.price, oi.quantity, oi.base_discount + COALESCE(od.discount, 0) as discount, COALESCE(ot.tax, 0) as tax, 0 as tax_included, 0 as shipping, om.customer, om.customer_name, om.status, om.canceled FROM temp_order_items oi JOIN temp_order_meta om ON oi.order_id = om.order_id LEFT JOIN temp_order_discounts od ON oi.order_id = od.order_id AND oi.pid = od.pid LEFT JOIN temp_order_taxes ot ON oi.order_id = ot.order_id AND oi.pid = ot.pid WHERE oi.order_id IN (?) `, [batchIds]); // Filter orders and track missing products - do this in a single pass const validOrders = []; const values = []; for (const order of orders) { if (!existingPids.has(order.pid)) { missingProducts.add(order.pid); skippedOrders.add(order.order_number); continue; } validOrders.push(order); values.push(...columnNames.map(col => order[col] ?? null)); } if (validOrders.length > 0) { // Pre-compute the placeholders string once const singlePlaceholder = `(${columnNames.map(() => "?").join(",")})`; const placeholders = Array(validOrders.length).fill(singlePlaceholder).join(","); // 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]) ); // 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; } outputProgress({ status: "running", operation: "Orders import", message: `Imported ${importedCount} of ${totalOrders} orders`, current: importedCount, total: totalOrders, elapsed: formatElapsedTime((Date.now() - startTime) / 1000), remaining: estimateRemaining(startTime, importedCount, totalOrders), rate: calculateRate(startTime, importedCount) }); } // Clean up temporary tables await localConnection.query(` DROP TEMPORARY TABLE IF EXISTS temp_order_items; DROP TEMPORARY TABLE IF EXISTS temp_order_meta; DROP TEMPORARY TABLE IF EXISTS temp_order_discounts; DROP TEMPORARY TABLE IF EXISTS temp_order_taxes; `); // Import missing products if any if (missingProducts.size > 0) { try { // Import missing products directly without materialization 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 skippedOrdersArray = Array.from(skippedOrders); const [skippedProdOrders] = skippedOrdersArray.length > 0 ? 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 (?) `, [skippedOrdersArray]) : [[]]; // 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`, }); } } catch (error) { console.warn('Warning: Failed to import missing products:', error.message); console.warn(`Skipped ${skippedOrders.size} orders due to ${missingProducts.size} missing products`); } } // Only update sync status if we get here (no errors thrown) 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, recordsAdded: recordsAdded || 0, recordsUpdated: recordsUpdated || 0, totalSkipped: skippedOrders.size, missingProducts: missingProducts.size, incrementalUpdate, lastSyncTime }; } catch (error) { console.error("Error during orders import:", error); throw error; } } module.exports = importOrders;