Optimize imports, fix up tracking records and time overall

This commit is contained in:
2025-06-19 11:15:04 -04:00
parent a97819f4a6
commit 8606a90e34
16 changed files with 601 additions and 85 deletions

View File

@@ -92,6 +92,12 @@ async function importCategories(prodConnection, localConnection) {
description = EXCLUDED.description,
status = EXCLUDED.status,
updated_at = EXCLUDED.updated_at
WHERE -- Only update if at least one field has changed
categories.name IS DISTINCT FROM EXCLUDED.name OR
categories.type IS DISTINCT FROM EXCLUDED.type OR
categories.parent_id IS DISTINCT FROM EXCLUDED.parent_id OR
categories.description IS DISTINCT FROM EXCLUDED.description OR
categories.status IS DISTINCT FROM EXCLUDED.status
RETURNING
cat_id,
CASE
@@ -133,7 +139,7 @@ async function importCategories(prodConnection, localConnection) {
message: `Imported ${inserted} (updated ${updated}) categories of type ${type}`,
current: totalInserted + totalUpdated,
total: categories.length,
elapsed: formatElapsedTime((Date.now() - startTime) / 1000),
elapsed: formatElapsedTime(startTime),
});
} catch (error) {
// Rollback to the savepoint for this type
@@ -161,7 +167,7 @@ async function importCategories(prodConnection, localConnection) {
operation: "Categories import completed",
current: totalInserted + totalUpdated,
total: totalInserted + totalUpdated,
duration: formatElapsedTime((Date.now() - startTime) / 1000),
duration: formatElapsedTime(startTime),
warnings: skippedCategories.length > 0 ? {
message: "Some categories were skipped due to missing parents",
skippedCategories

View File

@@ -221,8 +221,8 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
message: `Loading order items: ${processedCount} of ${totalOrderItems}`,
current: processedCount,
total: totalOrderItems,
elapsed: formatElapsedTime((Date.now() - startTime) / 1000),
remaining: estimateRemaining(startTime, processedCount, totalOrderItems),
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, processedCount, totalOrderItems),
rate: calculateRate(startTime, processedCount)
});
} catch (error) {
@@ -530,8 +530,8 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
message: `Loading order data: ${processedCount} of ${totalUniqueOrders}`,
current: processedCount,
total: totalUniqueOrders,
elapsed: formatElapsedTime((Date.now() - startTime) / 1000),
remaining: estimateRemaining(startTime, processedCount, totalUniqueOrders),
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, processedCount, totalUniqueOrders),
rate: calculateRate(startTime, processedCount)
});
}
@@ -681,6 +681,15 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
status = EXCLUDED.status,
canceled = EXCLUDED.canceled,
costeach = EXCLUDED.costeach
WHERE -- Only update if at least one key field has changed
orders.price IS DISTINCT FROM EXCLUDED.price OR
orders.quantity IS DISTINCT FROM EXCLUDED.quantity OR
orders.discount IS DISTINCT FROM EXCLUDED.discount OR
orders.tax IS DISTINCT FROM EXCLUDED.tax OR
orders.status IS DISTINCT FROM EXCLUDED.status OR
orders.canceled IS DISTINCT FROM EXCLUDED.canceled OR
orders.costeach IS DISTINCT FROM EXCLUDED.costeach OR
orders.date IS DISTINCT FROM EXCLUDED.date
RETURNING xmax = 0 as inserted
)
SELECT
@@ -704,7 +713,7 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
message: `Importing orders: ${cumulativeProcessedOrders} of ${totalUniqueOrders}`,
current: cumulativeProcessedOrders,
total: totalUniqueOrders,
elapsed: formatElapsedTime((Date.now() - startTime) / 1000),
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, cumulativeProcessedOrders, totalUniqueOrders),
rate: calculateRate(startTime, cumulativeProcessedOrders)
});
@@ -751,8 +760,15 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
recordsUpdated: parseInt(recordsUpdated) || 0,
totalSkipped: skippedOrders.size || 0,
missingProducts: missingProducts.size || 0,
totalProcessed: orderItems.length, // Total order items in source
incrementalUpdate,
lastSyncTime
lastSyncTime,
details: {
uniqueOrdersProcessed: cumulativeProcessedOrders,
totalOrderItems: orderItems.length,
skippedDueToMissingProducts: skippedOrders.size,
missingProductIds: Array.from(missingProducts).slice(0, 100) // First 100 for debugging
}
};
} catch (error) {
console.error("Error during orders import:", error);

View File

@@ -576,8 +576,8 @@ async function materializeCalculations(prodConnection, localConnection, incremen
message: `Imported ${i + batch.length} of ${prodData.length} products`,
current: i + batch.length,
total: prodData.length,
elapsed: formatElapsedTime((Date.now() - startTime) / 1000),
remaining: estimateRemaining(startTime, i + batch.length, prodData.length),
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, i + batch.length, prodData.length),
rate: calculateRate(startTime, i + batch.length)
});
}
@@ -587,6 +587,59 @@ async function materializeCalculations(prodConnection, localConnection, incremen
operation: "Products import",
message: "Finished materializing calculations"
});
// Add step to identify which products actually need updating
outputProgress({
status: "running",
operation: "Products import",
message: "Identifying changed products"
});
// Mark products that haven't changed as needs_update = false
await localConnection.query(`
UPDATE temp_products t
SET needs_update = FALSE
FROM products p
WHERE t.pid = p.pid
AND t.title IS NOT DISTINCT FROM p.title
AND t.description IS NOT DISTINCT FROM p.description
AND t.sku IS NOT DISTINCT FROM p.sku
AND t.stock_quantity = p.stock_quantity
AND t.price = p.price
AND t.regular_price = p.regular_price
AND t.cost_price IS NOT DISTINCT FROM p.cost_price
AND t.vendor IS NOT DISTINCT FROM p.vendor
AND t.brand IS NOT DISTINCT FROM p.brand
AND t.visible = p.visible
AND t.replenishable = p.replenishable
AND t.barcode IS NOT DISTINCT FROM p.barcode
AND t.updated_at IS NOT DISTINCT FROM p.updated_at
AND t.total_sold IS NOT DISTINCT FROM p.total_sold
-- Check key fields that are likely to change
-- We don't need to check every single field, just the important ones
`);
// Get count of products that need updating
const [countResult] = await localConnection.query(`
SELECT
COUNT(*) FILTER (WHERE needs_update = true) as update_count,
COUNT(*) FILTER (WHERE needs_update = false) as skip_count,
COUNT(*) as total_count
FROM temp_products
`);
outputProgress({
status: "running",
operation: "Products import",
message: `Found ${countResult.rows[0].update_count} products that need updating, ${countResult.rows[0].skip_count} unchanged`
});
// Return the total products processed
return {
totalProcessed: prodData.length,
needsUpdate: parseInt(countResult.rows[0].update_count),
skipped: parseInt(countResult.rows[0].skip_count)
};
}
async function importProducts(prodConnection, localConnection, incrementalUpdate = true) {
@@ -612,7 +665,7 @@ async function importProducts(prodConnection, localConnection, incrementalUpdate
await setupTemporaryTables(localConnection);
// Materialize calculations into temp table
await materializeCalculations(prodConnection, localConnection, incrementalUpdate, lastSyncTime, startTime);
const materializeResult = await materializeCalculations(prodConnection, localConnection, incrementalUpdate, lastSyncTime, startTime);
// Get the list of products that need updating
const [products] = await localConnection.query(`
@@ -847,8 +900,8 @@ async function importProducts(prodConnection, localConnection, incrementalUpdate
message: `Processing products: ${i + batch.length} of ${products.rows.length}`,
current: i + batch.length,
total: products.rows.length,
elapsed: formatElapsedTime((Date.now() - startTime) / 1000),
remaining: estimateRemaining(startTime, i + batch.length, products.rows.length),
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, i + batch.length, products.rows.length),
rate: calculateRate(startTime, i + batch.length)
});
}
@@ -872,7 +925,10 @@ async function importProducts(prodConnection, localConnection, incrementalUpdate
recordsAdded,
recordsUpdated,
totalRecords: products.rows.length,
duration: formatElapsedTime(Date.now() - startTime)
totalProcessed: materializeResult.totalProcessed,
duration: formatElapsedTime(startTime),
needsUpdate: materializeResult.needsUpdate,
skippedUnchanged: materializeResult.skipped
};
} catch (error) {
// Rollback on error

View File

@@ -398,7 +398,7 @@ async function importPurchaseOrders(prodConnection, localConnection, incremental
message: `Processed ${offset} of ${totalPOs} purchase orders (${totalProcessed} line items)`,
current: offset,
total: totalPOs,
elapsed: formatElapsedTime((Date.now() - startTime) / 1000),
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, offset, totalPOs),
rate: calculateRate(startTime, offset)
});
@@ -605,7 +605,7 @@ async function importPurchaseOrders(prodConnection, localConnection, incremental
message: `Processed ${offset} of ${totalReceivings} receivings (${totalProcessed} line items total)`,
current: offset,
total: totalReceivings,
elapsed: formatElapsedTime((Date.now() - startTime) / 1000),
elapsed: formatElapsedTime(startTime),
remaining: estimateRemaining(startTime, offset, totalReceivings),
rate: calculateRate(startTime, offset)
});
@@ -730,6 +730,13 @@ async function importPurchaseOrders(prodConnection, localConnection, incremental
date_created = EXCLUDED.date_created,
date_ordered = EXCLUDED.date_ordered,
updated = CURRENT_TIMESTAMP
WHERE -- Only update if at least one key field has changed
purchase_orders.ordered IS DISTINCT FROM EXCLUDED.ordered OR
purchase_orders.po_cost_price IS DISTINCT FROM EXCLUDED.po_cost_price OR
purchase_orders.status IS DISTINCT FROM EXCLUDED.status OR
purchase_orders.expected_date IS DISTINCT FROM EXCLUDED.expected_date OR
purchase_orders.date IS DISTINCT FROM EXCLUDED.date OR
purchase_orders.vendor IS DISTINCT FROM EXCLUDED.vendor
RETURNING (xmax = 0) as inserted
`);
@@ -806,6 +813,12 @@ async function importPurchaseOrders(prodConnection, localConnection, incremental
supplier_id = EXCLUDED.supplier_id,
status = EXCLUDED.status,
updated = CURRENT_TIMESTAMP
WHERE -- Only update if at least one key field has changed
receivings.qty_each IS DISTINCT FROM EXCLUDED.qty_each OR
receivings.cost_each IS DISTINCT FROM EXCLUDED.cost_each OR
receivings.status IS DISTINCT FROM EXCLUDED.status OR
receivings.received_date IS DISTINCT FROM EXCLUDED.received_date OR
receivings.received_by IS DISTINCT FROM EXCLUDED.received_by
RETURNING (xmax = 0) as inserted
`);