235 lines
7.6 KiB
JavaScript
235 lines
7.6 KiB
JavaScript
const { updateProgress, outputProgress, formatElapsedTime } = require('./utils');
|
|
const { importMissingProducts } = require('./products');
|
|
|
|
async function importOrders(prodConnection, localConnection) {
|
|
outputProgress({
|
|
operation: "Starting orders import - Getting total count",
|
|
status: "running",
|
|
});
|
|
|
|
const startTime = Date.now();
|
|
const skippedOrders = new Set(); // Store orders that need to be retried
|
|
const missingProducts = new Set(); // Store products that need to be imported
|
|
|
|
try {
|
|
// First get the column names from the table structure
|
|
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)
|
|
.filter((name) => name !== "id"); // Skip auto-increment ID
|
|
|
|
// Get total count first for progress indication
|
|
outputProgress({
|
|
operation: "Starting orders import - Getting total count",
|
|
status: "running",
|
|
});
|
|
|
|
const [countResult] = await prodConnection.query(`
|
|
SELECT COUNT(*) as total
|
|
FROM order_items oi FORCE INDEX (PRIMARY)
|
|
JOIN _order o FORCE INDEX (PRIMARY) ON oi.order_id = o.order_id
|
|
WHERE o.order_status >= 15
|
|
AND o.date_placed_onlydate >= DATE_SUB(CURRENT_DATE, INTERVAL 2 YEAR)
|
|
`);
|
|
const totalOrders = countResult[0].total;
|
|
|
|
outputProgress({
|
|
operation: `Starting orders import - Fetching ${totalOrders} orders from production`,
|
|
status: "running",
|
|
});
|
|
|
|
const total = countResult[0].total;
|
|
let processed = 0;
|
|
|
|
// Process in batches
|
|
const batchSize = 1000;
|
|
let offset = 0;
|
|
|
|
while (offset < total) {
|
|
const [orders] = 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_reg as price,
|
|
oi.qty_ordered as quantity,
|
|
(oi.prod_price_reg - oi.prod_price) as discount,
|
|
(
|
|
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,
|
|
ROUND(
|
|
((o.summary_shipping - COALESCE(o.summary_discount_shipping, 0)) *
|
|
(oi.prod_price * oi.qty_ordered) / NULLIF(o.summary_subtotal, 0)), 2
|
|
) as shipping,
|
|
o.order_cid as customer,
|
|
CONCAT(o.bill_firstname, ' ', o.bill_lastname) as customer_name,
|
|
'pending' as status,
|
|
CASE WHEN o.order_status = 15 THEN 1 ELSE 0 END as canceled
|
|
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 2 YEAR)
|
|
LIMIT ? OFFSET ?
|
|
`, [batchSize, offset]);
|
|
|
|
// Check if all products exist before inserting orders
|
|
const orderProductPids = [...new Set(orders.map((o) => o.pid))];
|
|
const [existingProducts] = await localConnection.query(
|
|
"SELECT pid FROM products WHERE pid IN (?)",
|
|
[orderProductPids]
|
|
);
|
|
const existingPids = new Set(existingProducts.map((p) => p.pid));
|
|
|
|
// Filter out orders with missing products and track them
|
|
const validOrders = orders.filter((order) => {
|
|
if (!existingPids.has(order.pid)) {
|
|
missingProducts.add(order.pid);
|
|
skippedOrders.add(order.order_number);
|
|
return false;
|
|
}
|
|
return true;
|
|
});
|
|
|
|
if (validOrders.length > 0) {
|
|
const placeholders = validOrders
|
|
.map(() => `(${Array(columnNames.length).fill("?").join(",")})`)
|
|
.join(",");
|
|
const updateClauses = columnNames
|
|
.filter((col) => col !== "order_number") // Don't update primary key
|
|
.map((col) => `${col} = VALUES(${col})`)
|
|
.join(",");
|
|
|
|
const query = `
|
|
INSERT INTO orders (${columnNames.join(",")})
|
|
VALUES ${placeholders}
|
|
ON DUPLICATE KEY UPDATE ${updateClauses}
|
|
`;
|
|
|
|
await localConnection.query(
|
|
query,
|
|
validOrders.flatMap(order => columnNames.map(col => order[col]))
|
|
);
|
|
}
|
|
|
|
processed += orders.length;
|
|
offset += batchSize;
|
|
|
|
updateProgress(
|
|
processed,
|
|
total,
|
|
"Orders import",
|
|
startTime
|
|
);
|
|
}
|
|
|
|
// Now handle missing products and retry skipped orders
|
|
if (missingProducts.size > 0) {
|
|
outputProgress({
|
|
operation: `Found ${missingProducts.size} missing products, importing them now`,
|
|
status: "running",
|
|
});
|
|
|
|
await importMissingProducts(prodConnection, localConnection, [
|
|
...missingProducts,
|
|
]);
|
|
|
|
// Retry skipped orders
|
|
if (skippedOrders.size > 0) {
|
|
outputProgress({
|
|
operation: `Retrying ${skippedOrders.size} skipped orders`,
|
|
status: "running",
|
|
});
|
|
|
|
const [retryOrders] = 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_reg as price,
|
|
oi.qty_ordered as quantity,
|
|
(oi.prod_price_reg - oi.prod_price) as discount,
|
|
(
|
|
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,
|
|
ROUND(
|
|
((o.summary_shipping - COALESCE(o.summary_discount_shipping, 0)) *
|
|
(oi.prod_price * oi.qty_ordered) / NULLIF(o.summary_subtotal, 0)), 2
|
|
) as shipping,
|
|
o.order_cid as customer,
|
|
CONCAT(o.bill_firstname, ' ', o.bill_lastname) as customer_name,
|
|
'pending' as status,
|
|
CASE WHEN o.order_status = 15 THEN 1 ELSE 0 END as canceled
|
|
FROM order_items oi
|
|
JOIN _order o ON oi.order_id = o.order_id
|
|
WHERE oi.order_id IN (?)
|
|
`, [[...skippedOrders]]);
|
|
|
|
const placeholders = retryOrders
|
|
.map(() => `(${Array(columnNames.length).fill("?").join(",")})`)
|
|
.join(",");
|
|
const updateClauses = columnNames
|
|
.filter((col) => col !== "order_number") // Don't update primary key
|
|
.map((col) => `${col} = VALUES(${col})`)
|
|
.join(",");
|
|
|
|
const query = `
|
|
INSERT INTO orders (${columnNames.join(",")})
|
|
VALUES ${placeholders}
|
|
ON DUPLICATE KEY UPDATE ${updateClauses}
|
|
`;
|
|
|
|
await localConnection.query(
|
|
query,
|
|
retryOrders.flatMap(order => columnNames.map(col => order[col]))
|
|
);
|
|
}
|
|
}
|
|
|
|
const endTime = Date.now();
|
|
outputProgress({
|
|
operation: `Orders import complete in ${Math.round(
|
|
(endTime - startTime) / 1000
|
|
)}s`,
|
|
status: "complete",
|
|
});
|
|
} catch (error) {
|
|
outputProgress({
|
|
operation: "Orders import failed",
|
|
status: "error",
|
|
error: error.message,
|
|
});
|
|
throw error;
|
|
}
|
|
}
|
|
|
|
module.exports = importOrders;
|