Get product_categories inserting and product import fully running
This commit is contained in:
@@ -62,7 +62,7 @@ CREATE TABLE products (
|
||||
|
||||
-- Create categories table with hierarchy support
|
||||
CREATE TABLE categories (
|
||||
cat_id BIGINT AUTO_INCREMENT PRIMARY KEY,
|
||||
cat_id BIGINT PRIMARY KEY,
|
||||
name VARCHAR(100) NOT NULL,
|
||||
type SMALLINT NOT NULL COMMENT '10=section, 11=category, 12=subcategory, 13=subsubcategory, 1=company, 2=line, 3=subline, 40=artist',
|
||||
parent_id BIGINT,
|
||||
|
||||
@@ -135,6 +135,9 @@ async function importCategories(prodConnection, localConnection) {
|
||||
if (categories.length === 0) continue;
|
||||
|
||||
console.log(`\nProcessing ${categories.length} type ${type} categories`);
|
||||
if (type === 10) {
|
||||
console.log('Type 10 categories:', JSON.stringify(categories, null, 2));
|
||||
}
|
||||
|
||||
// For types that can have parents (11, 21, 12, 13), verify parent existence
|
||||
let categoriesToInsert = categories;
|
||||
@@ -159,7 +162,7 @@ async function importCategories(prodConnection, localConnection) {
|
||||
|
||||
if (invalidCategories.length > 0) {
|
||||
const skippedInfo = invalidCategories.map(c => ({
|
||||
id: c.id,
|
||||
id: c.cat_id,
|
||||
name: c.name,
|
||||
type: c.type,
|
||||
missing_parent: c.parent_id
|
||||
@@ -167,7 +170,7 @@ async function importCategories(prodConnection, localConnection) {
|
||||
skippedCategories.push(...skippedInfo);
|
||||
|
||||
console.log('\nSkipping categories with missing parents:',
|
||||
invalidCategories.map(c => `${c.id} - ${c.name} (missing parent: ${c.parent_id})`).join('\n')
|
||||
invalidCategories.map(c => `${c.cat_id} - ${c.name} (missing parent: ${c.parent_id})`).join('\n')
|
||||
);
|
||||
}
|
||||
|
||||
@@ -242,178 +245,82 @@ async function importProducts(prodConnection, localConnection) {
|
||||
const startTime = Date.now();
|
||||
|
||||
try {
|
||||
// Get products from production
|
||||
// First get the column names from the table structure
|
||||
const [columns] = await localConnection.query(`
|
||||
SELECT COLUMN_NAME
|
||||
FROM INFORMATION_SCHEMA.COLUMNS
|
||||
WHERE TABLE_NAME = 'products'
|
||||
ORDER BY ORDINAL_POSITION
|
||||
`);
|
||||
|
||||
const columnNames = columns.map(col => col.COLUMN_NAME);
|
||||
|
||||
// Get products from production with optimized query
|
||||
const [rows] = await prodConnection.query(`
|
||||
SELECT
|
||||
p.pid AS product_id,
|
||||
p.pid,
|
||||
p.description AS title,
|
||||
p.notes AS description,
|
||||
p.itemnumber AS SKU,
|
||||
p.date_created AS created_at,
|
||||
p.date_created,
|
||||
p.datein AS first_received,
|
||||
p.location AS location,
|
||||
(
|
||||
SELECT
|
||||
i.available_local - COALESCE(
|
||||
(
|
||||
SELECT
|
||||
SUM(oi.qty_ordered - oi.qty_placed)
|
||||
FROM
|
||||
order_items oi
|
||||
JOIN _order o ON oi.order_id = o.order_id
|
||||
WHERE
|
||||
oi.prod_pid = i.pid
|
||||
AND o.date_placed != '0000-00-00 00:00:00'
|
||||
AND o.date_shipped = '0000-00-00 00:00:00'
|
||||
AND oi.pick_finished = 0
|
||||
AND oi.qty_back = 0
|
||||
AND o.order_status != 15
|
||||
AND o.order_status < 90
|
||||
AND oi.qty_ordered >= oi.qty_placed
|
||||
AND oi.qty_ordered > 0
|
||||
),
|
||||
0
|
||||
) AS stock_quantity
|
||||
FROM
|
||||
shop_inventory i
|
||||
WHERE
|
||||
i.pid = p.pid
|
||||
AND i.store = 0
|
||||
AND i.show + i.buyable > 0
|
||||
LIMIT 1
|
||||
) AS stock_quantity,
|
||||
p.location,
|
||||
COALESCE(si.available_local, 0) - COALESCE(
|
||||
(SELECT SUM(oi.qty_ordered - oi.qty_placed)
|
||||
FROM order_items oi
|
||||
JOIN _order o ON oi.order_id = o.order_id
|
||||
WHERE oi.prod_pid = p.pid
|
||||
AND o.date_placed != '0000-00-00 00:00:00'
|
||||
AND o.date_shipped = '0000-00-00 00:00:00'
|
||||
AND oi.pick_finished = 0
|
||||
AND oi.qty_back = 0
|
||||
AND o.order_status != 15
|
||||
AND o.order_status < 90
|
||||
AND oi.qty_ordered >= oi.qty_placed
|
||||
AND oi.qty_ordered > 0), 0) AS stock_quantity,
|
||||
ci.onpreorder AS preorder_count,
|
||||
pnb.inventory AS notions_inv_count,
|
||||
(
|
||||
SELECT
|
||||
price_each
|
||||
FROM
|
||||
product_current_prices
|
||||
WHERE
|
||||
pid = p.pid
|
||||
AND active = 1
|
||||
ORDER BY
|
||||
qty_buy ASC
|
||||
LIMIT 1
|
||||
) AS price,
|
||||
p.sellingprice AS regular_price,
|
||||
(
|
||||
SELECT
|
||||
ROUND(AVG(costeach), 5)
|
||||
FROM
|
||||
product_inventory
|
||||
WHERE
|
||||
pid = p.pid
|
||||
AND COUNT > 0
|
||||
) AS cost_price,
|
||||
COALESCE(pcp.price_each, 0) as price,
|
||||
COALESCE(p.sellingprice, 0) AS regular_price,
|
||||
COALESCE((SELECT ROUND(AVG(costeach), 5)
|
||||
FROM product_inventory
|
||||
WHERE pid = p.pid
|
||||
AND COUNT > 0), 0) AS cost_price,
|
||||
NULL AS landing_cost_price,
|
||||
p.upc AS barcode,
|
||||
p.harmonized_tariff_code AS harmonized_tariff_code,
|
||||
p.harmonized_tariff_code,
|
||||
p.stamp AS updated_at,
|
||||
CASE
|
||||
WHEN si.show + si.buyable > 0 THEN 1
|
||||
ELSE 0
|
||||
END AS visible,
|
||||
CASE
|
||||
WHEN p.reorder >= 0 THEN 1
|
||||
ELSE 0
|
||||
END AS replenishable,
|
||||
CASE WHEN si.show + si.buyable > 0 THEN 1 ELSE 0 END AS visible,
|
||||
CASE WHEN p.reorder >= 0 THEN 1 ELSE 0 END AS replenishable,
|
||||
s.companyname AS vendor,
|
||||
sid.supplier_itemnumber AS vendor_reference,
|
||||
sid.notions_itemnumber AS notions_reference,
|
||||
CONCAT('https://www.acherryontop.com/shop/product/', p.pid) AS permalink,
|
||||
(
|
||||
SELECT
|
||||
GROUP_CONCAT(pc.name SEPARATOR ', ')
|
||||
FROM
|
||||
product_category_index pci
|
||||
JOIN product_categories pc ON pci.cat_id = pc.cat_id
|
||||
WHERE
|
||||
pci.pid = p.pid
|
||||
AND pc.hidden = 0
|
||||
) AS categories,
|
||||
(
|
||||
SELECT
|
||||
CONCAT('https://sbing.com/i/products/0000/', SUBSTRING(LPAD(p.pid, 6, '0'), 1, 3), '/', p.pid, '-t-', PI.iid, '.jpg')
|
||||
FROM
|
||||
product_images PI
|
||||
WHERE
|
||||
PI.pid = p.pid
|
||||
AND PI.hidden = 0
|
||||
ORDER BY
|
||||
PI.order DESC,
|
||||
PI.iid
|
||||
LIMIT 1
|
||||
) AS image,
|
||||
(
|
||||
SELECT
|
||||
CONCAT('https://sbing.com/i/products/0000/', SUBSTRING(LPAD(p.pid, 6, '0'), 1, 3), '/', p.pid, '-175x175-', PI.iid, '.jpg')
|
||||
FROM
|
||||
product_images PI
|
||||
WHERE
|
||||
PI.pid = p.pid
|
||||
AND PI.hidden = 0
|
||||
AND PI.width = 175
|
||||
ORDER BY
|
||||
PI.order DESC,
|
||||
PI.iid
|
||||
LIMIT 1
|
||||
) AS image_175,
|
||||
(
|
||||
SELECT
|
||||
CONCAT('https://sbing.com/i/products/0000/', SUBSTRING(LPAD(p.pid, 6, '0'), 1, 3), '/', p.pid, '-o-', PI.iid, '.jpg')
|
||||
FROM
|
||||
product_images PI
|
||||
WHERE
|
||||
PI.pid = p.pid
|
||||
AND PI.hidden = 0
|
||||
ORDER BY
|
||||
PI.width DESC,
|
||||
PI.height DESC,
|
||||
PI.iid
|
||||
LIMIT 1
|
||||
) AS image_full,
|
||||
(
|
||||
SELECT
|
||||
name
|
||||
FROM
|
||||
product_categories
|
||||
WHERE
|
||||
cat_id = p.company
|
||||
) AS brand,
|
||||
(
|
||||
SELECT
|
||||
name
|
||||
FROM
|
||||
product_categories
|
||||
WHERE
|
||||
cat_id = p.line
|
||||
) AS line,
|
||||
(
|
||||
SELECT
|
||||
name
|
||||
FROM
|
||||
product_categories
|
||||
WHERE
|
||||
cat_id = p.subline
|
||||
) AS subline,
|
||||
(
|
||||
SELECT
|
||||
name
|
||||
FROM
|
||||
product_categories
|
||||
WHERE
|
||||
cat_id = p.artist
|
||||
) AS artist,
|
||||
(SELECT CONCAT('https://sbing.com/i/products/0000/',
|
||||
SUBSTRING(LPAD(p.pid, 6, '0'), 1, 3), '/',
|
||||
p.pid, '-t-', MIN(PI.iid), '.jpg')
|
||||
FROM product_images PI
|
||||
WHERE PI.pid = p.pid AND PI.hidden = 0) AS image,
|
||||
(SELECT CONCAT('https://sbing.com/i/products/0000/',
|
||||
SUBSTRING(LPAD(p.pid, 6, '0'), 1, 3), '/',
|
||||
p.pid, '-175x175-', MIN(PI.iid), '.jpg')
|
||||
FROM product_images PI
|
||||
WHERE PI.pid = p.pid AND PI.hidden = 0 AND PI.width = 175) AS image_175,
|
||||
(SELECT CONCAT('https://sbing.com/i/products/0000/',
|
||||
SUBSTRING(LPAD(p.pid, 6, '0'), 1, 3), '/',
|
||||
p.pid, '-o-', MIN(PI.iid), '.jpg')
|
||||
FROM product_images PI
|
||||
WHERE PI.pid = p.pid AND PI.hidden = 0) AS image_full,
|
||||
pc1.name AS brand,
|
||||
pc2.name AS line,
|
||||
pc3.name AS subline,
|
||||
pc4.name AS artist,
|
||||
NULL AS options,
|
||||
NULL AS tags,
|
||||
COALESCE(
|
||||
CASE
|
||||
WHEN sid.supplier_id = 92 THEN sid.notions_qty_per_unit
|
||||
ELSE sid.supplier_qty_per_unit
|
||||
END,
|
||||
sid.notions_qty_per_unit
|
||||
) AS moq,
|
||||
COALESCE(CASE
|
||||
WHEN sid.supplier_id = 92 THEN sid.notions_qty_per_unit
|
||||
ELSE sid.supplier_qty_per_unit
|
||||
END, sid.notions_qty_per_unit) AS moq,
|
||||
NULL AS uom,
|
||||
p.rating,
|
||||
p.rating_votes AS reviews,
|
||||
@@ -421,36 +328,31 @@ async function importProducts(prodConnection, localConnection) {
|
||||
p.length,
|
||||
p.width,
|
||||
p.height,
|
||||
(
|
||||
SELECT
|
||||
COUNT(*)
|
||||
FROM
|
||||
mybasket mb
|
||||
WHERE
|
||||
mb.item = p.pid
|
||||
AND mb.qty > 0
|
||||
) AS baskets,
|
||||
(
|
||||
SELECT
|
||||
COUNT(*)
|
||||
FROM
|
||||
product_notify pn
|
||||
WHERE
|
||||
pn.pid = p.pid
|
||||
) AS notifies,
|
||||
(SELECT COUNT(*) FROM mybasket mb WHERE mb.item = p.pid AND mb.qty > 0) AS baskets,
|
||||
(SELECT COUNT(*) FROM product_notify pn WHERE pn.pid = p.pid) AS notifies,
|
||||
p.totalsold AS total_sold,
|
||||
p.country_of_origin as country_of_origin,
|
||||
pls.date_sold as date_last_sold
|
||||
FROM
|
||||
products p
|
||||
LEFT JOIN current_inventory ci ON p.pid = ci.pid
|
||||
LEFT JOIN product_notions_b2b pnb ON p.pid = pnb.pid
|
||||
LEFT JOIN shop_inventory si ON p.pid = si.pid AND si.store = 0
|
||||
LEFT JOIN supplier_item_data sid ON p.pid = sid.pid
|
||||
LEFT JOIN suppliers s ON sid.supplier_id = s.supplierid
|
||||
LEFT JOIN product_category_index pci ON p.pid = pci.pid
|
||||
LEFT JOIN product_categories pc ON pci.cat_id = pc.cat_id
|
||||
LEFT JOIN product_last_sold pls ON p.pid = pls.pid
|
||||
p.country_of_origin,
|
||||
pls.date_sold as date_last_sold,
|
||||
GROUP_CONCAT(DISTINCT CASE WHEN pc.cat_id IS NOT NULL THEN pci.cat_id END) as category_ids
|
||||
FROM products p
|
||||
LEFT JOIN current_inventory ci ON p.pid = ci.pid
|
||||
LEFT JOIN product_notions_b2b pnb ON p.pid = pnb.pid
|
||||
LEFT JOIN shop_inventory si ON p.pid = si.pid AND si.store = 0
|
||||
LEFT JOIN supplier_item_data sid ON p.pid = sid.pid
|
||||
LEFT JOIN suppliers s ON sid.supplier_id = s.supplierid
|
||||
LEFT JOIN product_category_index pci ON p.pid = pci.pid
|
||||
LEFT JOIN product_categories pc ON pci.cat_id = pc.cat_id AND pc.type IN (10, 20, 11, 21, 12, 13)
|
||||
LEFT JOIN product_categories pc1 ON p.company = pc1.cat_id
|
||||
LEFT JOIN product_categories pc2 ON p.line = pc2.cat_id
|
||||
LEFT JOIN product_categories pc3 ON p.subline = pc3.cat_id
|
||||
LEFT JOIN product_categories pc4 ON p.artist = pc4.cat_id
|
||||
LEFT JOIN product_last_sold pls ON p.pid = pls.pid
|
||||
LEFT JOIN (
|
||||
SELECT pid, MIN(price_each) as price_each
|
||||
FROM product_current_prices
|
||||
WHERE active = 1
|
||||
GROUP BY pid
|
||||
) pcp ON p.pid = pcp.pid
|
||||
WHERE p.date_created >= DATE_SUB(CURRENT_DATE, INTERVAL 2 YEAR)
|
||||
GROUP BY p.pid
|
||||
`);
|
||||
@@ -458,113 +360,105 @@ async function importProducts(prodConnection, localConnection) {
|
||||
let current = 0;
|
||||
const total = rows.length;
|
||||
|
||||
// Process products in batches
|
||||
// Process products in larger batches
|
||||
const BATCH_SIZE = 100;
|
||||
for (let i = 0; i < rows.length; i += BATCH_SIZE) {
|
||||
const batch = rows.slice(i, i + BATCH_SIZE);
|
||||
|
||||
console.log(`Inserting ${batch.length} products`);
|
||||
// Prepare product values and category relationships in parallel
|
||||
const productValues = [];
|
||||
const categoryRelationships = [];
|
||||
|
||||
// First insert the products
|
||||
const values = batch.flatMap(r => [
|
||||
r.product_id, r.title, r.description, r.SKU, r.created_at, r.first_received,
|
||||
r.stock_quantity, r.preorder_count, r.notions_inv_count, r.price, r.regular_price,
|
||||
r.cost_price, r.landing_cost_price, r.barcode, r.harmonized_tariff_code,
|
||||
r.updated_at, r.visible, 1, r.replenishable, r.vendor,
|
||||
r.vendor_reference, r.notions_reference, r.permalink,
|
||||
r.image, r.image_175, r.image_full, r.brand, r.line, r.subline, r.artist,
|
||||
r.options, r.tags, r.moq, r.uom, r.rating, r.reviews, r.weight, r.length,
|
||||
r.width, r.height, r.country_of_origin, r.location, r.total_sold,
|
||||
r.baskets, r.notifies, r.date_last_sold
|
||||
]);
|
||||
batch.forEach(row => {
|
||||
// Map values in the same order as columns
|
||||
const rowValues = columnNames.map(col => {
|
||||
const val = row[col] ?? null;
|
||||
if (col === 'managing_stock') return 1;
|
||||
if (typeof val === 'number') return val || 0;
|
||||
return val;
|
||||
});
|
||||
productValues.push(...rowValues);
|
||||
|
||||
// Get the number of columns from the first row's values
|
||||
const columnsPerRow = values.length / batch.length;
|
||||
const placeholders = batch.map(() =>
|
||||
`(${Array(columnsPerRow).fill('?').join(',')})`
|
||||
).join(',');
|
||||
|
||||
const sql = `INSERT INTO products (
|
||||
pid, title, description, SKU, created_at, first_received,
|
||||
stock_quantity, preorder_count, notions_inv_count, price, regular_price,
|
||||
cost_price, landing_cost_price, barcode, harmonized_tariff_code,
|
||||
updated_at, visible, managing_stock, replenishable, vendor,
|
||||
vendor_reference, notions_reference, permalink,
|
||||
image, image_175, image_full, brand, line, subline, artist,
|
||||
options, tags, moq, uom, rating, reviews, weight, length,
|
||||
width, height, country_of_origin, location, total_sold,
|
||||
baskets, notifies, date_last_sold
|
||||
)
|
||||
VALUES ${placeholders}
|
||||
ON DUPLICATE KEY UPDATE
|
||||
title = VALUES(title),
|
||||
description = VALUES(description),
|
||||
stock_quantity = VALUES(stock_quantity),
|
||||
preorder_count = VALUES(preorder_count),
|
||||
notions_inv_count = VALUES(notions_inv_count),
|
||||
price = VALUES(price),
|
||||
regular_price = VALUES(regular_price),
|
||||
cost_price = VALUES(cost_price),
|
||||
landing_cost_price = VALUES(landing_cost_price),
|
||||
barcode = VALUES(barcode),
|
||||
harmonized_tariff_code = VALUES(harmonized_tariff_code),
|
||||
updated_at = VALUES(updated_at),
|
||||
visible = VALUES(visible),
|
||||
replenishable = VALUES(replenishable),
|
||||
vendor = VALUES(vendor),
|
||||
vendor_reference = VALUES(vendor_reference),
|
||||
notions_reference = VALUES(notions_reference),
|
||||
permalink = VALUES(permalink),
|
||||
image = VALUES(image),
|
||||
image_175 = VALUES(image_175),
|
||||
image_full = VALUES(image_full),
|
||||
brand = VALUES(brand),
|
||||
line = VALUES(line),
|
||||
subline = VALUES(subline),
|
||||
artist = VALUES(artist),
|
||||
options = VALUES(options),
|
||||
tags = VALUES(tags),
|
||||
moq = VALUES(moq),
|
||||
uom = VALUES(uom),
|
||||
rating = VALUES(rating),
|
||||
reviews = VALUES(reviews),
|
||||
weight = VALUES(weight),
|
||||
length = VALUES(length),
|
||||
width = VALUES(width),
|
||||
height = VALUES(height),
|
||||
country_of_origin = VALUES(country_of_origin),
|
||||
location = VALUES(location),
|
||||
total_sold = VALUES(total_sold),
|
||||
baskets = VALUES(baskets),
|
||||
notifies = VALUES(notifies),
|
||||
date_last_sold = VALUES(date_last_sold)`;
|
||||
|
||||
await localConnection.query(sql, values);
|
||||
|
||||
// Then insert the category relationships for this batch
|
||||
const categoryPromises = batch.map(async product => {
|
||||
// Get the category IDs from the production query
|
||||
const [categoryRows] = await prodConnection.query(`
|
||||
SELECT DISTINCT cat_id
|
||||
FROM product_category_index
|
||||
WHERE pid = ? AND cat_id IN (
|
||||
SELECT cat_id FROM product_categories WHERE hidden = 0
|
||||
)
|
||||
`, [product.product_id]);
|
||||
|
||||
return categoryRows.map(row => [row.cat_id, product.product_id]);
|
||||
// Add category relationships
|
||||
if (row.category_ids) {
|
||||
const catIds = row.category_ids.split(',')
|
||||
.map(id => id.trim())
|
||||
.filter(id => id)
|
||||
.map(Number);
|
||||
catIds.forEach(catId => {
|
||||
if (catId) categoryRelationships.push([catId, row.pid]);
|
||||
});
|
||||
}
|
||||
});
|
||||
|
||||
const categoryResults = await Promise.all(categoryPromises);
|
||||
const categoryRelationships = categoryResults.flat();
|
||||
// Generate placeholders based on column count
|
||||
const placeholderGroup = `(${Array(columnNames.length).fill('?').join(',')})`;
|
||||
const productPlaceholders = Array(batch.length).fill(placeholderGroup).join(',');
|
||||
|
||||
// Build the query dynamically
|
||||
const insertQuery = `
|
||||
INSERT INTO products (${columnNames.join(',')})
|
||||
VALUES ${productPlaceholders}
|
||||
ON DUPLICATE KEY UPDATE ${
|
||||
columnNames
|
||||
.filter(col => col !== 'pid')
|
||||
.map(col => `${col} = VALUES(${col})`)
|
||||
.join(',')
|
||||
}
|
||||
`;
|
||||
|
||||
// First insert the products and wait for it to complete
|
||||
await localConnection.query(insertQuery, productValues);
|
||||
|
||||
// Now that products are inserted, handle category relationships
|
||||
if (categoryRelationships.length > 0) {
|
||||
const catPlaceholders = categoryRelationships.map(() => '(?, ?)').join(',');
|
||||
await localConnection.query(`
|
||||
INSERT INTO product_categories (cat_id, pid)
|
||||
VALUES ${catPlaceholders}
|
||||
ON DUPLICATE KEY UPDATE cat_id = VALUES(cat_id)
|
||||
`, categoryRelationships.flat());
|
||||
// Get unique category IDs to verify they exist
|
||||
const uniqueCatIds = [...new Set(categoryRelationships.map(([catId]) => catId))];
|
||||
|
||||
console.log('Checking categories:', uniqueCatIds);
|
||||
|
||||
// Check which categories exist
|
||||
const [existingCats] = await localConnection.query(
|
||||
'SELECT cat_id FROM categories WHERE cat_id IN (?)',
|
||||
[uniqueCatIds]
|
||||
);
|
||||
const existingCatIds = new Set(existingCats.map(c => c.cat_id));
|
||||
|
||||
// Log missing categories
|
||||
const missingCatIds = uniqueCatIds.filter(id => !existingCatIds.has(id));
|
||||
if (missingCatIds.length > 0) {
|
||||
console.error('Missing categories:', missingCatIds);
|
||||
|
||||
// Query production to see what these categories are
|
||||
const [missingCats] = await prodConnection.query(`
|
||||
SELECT cat_id, name, type, master_cat_id, hidden
|
||||
FROM product_categories
|
||||
WHERE cat_id IN (?)
|
||||
`, [missingCatIds]);
|
||||
|
||||
console.error('Missing category details:', missingCats);
|
||||
throw new Error('Missing categories found - import needs to be fixed');
|
||||
}
|
||||
|
||||
// Verify products exist before inserting relationships
|
||||
const productIds = [...new Set(categoryRelationships.map(([_, pid]) => pid))];
|
||||
const [existingProducts] = await localConnection.query(
|
||||
'SELECT pid FROM products WHERE pid IN (?)',
|
||||
[productIds]
|
||||
);
|
||||
const existingProductIds = new Set(existingProducts.map(p => p.pid));
|
||||
|
||||
// Filter relationships to only include existing products
|
||||
const validRelationships = categoryRelationships.filter(([_, pid]) => existingProductIds.has(pid));
|
||||
|
||||
if (validRelationships.length > 0) {
|
||||
const catPlaceholders = validRelationships.map(() => '(?, ?)').join(',');
|
||||
await localConnection.query(`
|
||||
INSERT INTO product_categories (cat_id, pid)
|
||||
VALUES ${catPlaceholders}
|
||||
ON DUPLICATE KEY UPDATE cat_id = VALUES(cat_id)
|
||||
`, validRelationships.flat());
|
||||
}
|
||||
}
|
||||
|
||||
current += batch.length;
|
||||
@@ -584,65 +478,6 @@ async function importProducts(prodConnection, localConnection) {
|
||||
}
|
||||
}
|
||||
|
||||
async function importProductCategories(prodConnection, localConnection) {
|
||||
outputProgress({
|
||||
operation: 'Starting product categories import',
|
||||
status: 'running'
|
||||
});
|
||||
|
||||
const startTime = Date.now();
|
||||
|
||||
try {
|
||||
// Get product category relationships from production
|
||||
const [rows] = await prodConnection.query(`
|
||||
SELECT DISTINCT
|
||||
pci.pid,
|
||||
pci.cat_id
|
||||
FROM
|
||||
product_category_index pci
|
||||
JOIN product_categories pc ON pci.cat_id = pc.cat_id
|
||||
WHERE
|
||||
pc.hidden = 0
|
||||
`);
|
||||
|
||||
let current = 0;
|
||||
const total = rows.length;
|
||||
|
||||
// Process in batches
|
||||
const BATCH_SIZE = 500;
|
||||
for (let i = 0; i < rows.length; i += BATCH_SIZE) {
|
||||
const batch = rows.slice(i, i + BATCH_SIZE);
|
||||
|
||||
// Create placeholders for batch insert
|
||||
const placeholders = batch.map(() => '(?, ?)').join(',');
|
||||
|
||||
// Flatten values for batch insert
|
||||
const values = batch.flatMap(row => [row.cat_id, row.pid]);
|
||||
|
||||
await localConnection.query(`
|
||||
INSERT INTO product_categories (cat_id, pid)
|
||||
VALUES ${placeholders}
|
||||
ON DUPLICATE KEY UPDATE
|
||||
cat_id = VALUES(cat_id)
|
||||
`, values);
|
||||
|
||||
current += batch.length;
|
||||
updateProgress(current, total, 'Product categories import', startTime);
|
||||
}
|
||||
|
||||
outputProgress({
|
||||
status: 'complete',
|
||||
operation: 'Product categories import completed',
|
||||
current: total,
|
||||
total,
|
||||
duration: formatDuration((Date.now() - startTime) / 1000)
|
||||
});
|
||||
} catch (error) {
|
||||
console.error('Error importing product categories:', error);
|
||||
throw error;
|
||||
}
|
||||
}
|
||||
|
||||
async function importOrders(prodConnection, localConnection) {
|
||||
outputProgress({
|
||||
operation: 'Starting orders import',
|
||||
@@ -908,10 +743,6 @@ async function main() {
|
||||
await importProducts(prodConnection, localConnection);
|
||||
if (isImportCancelled) throw new Error('Import cancelled');
|
||||
|
||||
// Then import product-category relationships
|
||||
await importProductCategories(prodConnection, localConnection);
|
||||
if (isImportCancelled) throw new Error('Import cancelled');
|
||||
|
||||
await importOrders(prodConnection, localConnection);
|
||||
if (isImportCancelled) throw new Error('Import cancelled');
|
||||
|
||||
|
||||
Reference in New Issue
Block a user