diff --git a/inventory-server/db/schema.sql b/inventory-server/db/schema.sql index a202739..3f779cc 100644 --- a/inventory-server/db/schema.sql +++ b/inventory-server/db/schema.sql @@ -148,7 +148,7 @@ CREATE TABLE purchase_orders ( received INT DEFAULT 0, received_date DATE COMMENT 'Date of first receiving', last_received_date DATE COMMENT 'Date of most recent receiving', - received_by INT, + received_by VARCHAR(100) COMMENT 'Name of person who first received this PO line', receiving_history JSON COMMENT 'Array of receiving records with qty, date, cost, receiving_id, and alt_po flag', FOREIGN KEY (pid) REFERENCES products(pid), INDEX idx_po_id (po_id), diff --git a/inventory-server/scripts/import/orders.js b/inventory-server/scripts/import/orders.js index 3a18d9d..cb9d5a7 100644 --- a/inventory-server/scripts/import/orders.js +++ b/inventory-server/scripts/import/orders.js @@ -28,9 +28,18 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate = let cumulativeProcessedOrders = 0; try { - // Insert temporary table creation queries + // Clean up any existing temp tables first await localConnection.query(` - CREATE TABLE IF NOT EXISTS temp_order_items ( + 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; + DROP TEMPORARY TABLE IF EXISTS temp_order_costs; + `); + + // Create all temp tables with correct schema + await localConnection.query(` + CREATE TEMPORARY TABLE temp_order_items ( order_id INT UNSIGNED NOT NULL, pid INT UNSIGNED NOT NULL, SKU VARCHAR(50) NOT NULL, @@ -40,35 +49,41 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate = PRIMARY KEY (order_id, pid) ) ENGINE=InnoDB DEFAULT CHARSET=utf8; `); + await localConnection.query(` - CREATE TABLE IF NOT EXISTS temp_order_meta ( + CREATE TEMPORARY TABLE 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), + summary_discount DECIMAL(10,2) DEFAULT 0.00, + summary_subtotal DECIMAL(10,2) DEFAULT 0.00, PRIMARY KEY (order_id) ) ENGINE=InnoDB DEFAULT CHARSET=utf8; `); + await localConnection.query(` - CREATE TABLE IF NOT EXISTS temp_order_discounts ( + CREATE TEMPORARY TABLE 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 ( + CREATE TEMPORARY TABLE 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; `); + await localConnection.query(` - CREATE TABLE IF NOT EXISTS temp_order_costs ( + CREATE TEMPORARY TABLE temp_order_costs ( order_id INT UNSIGNED NOT NULL, pid INT UNSIGNED NOT NULL, costeach DECIMAL(10,3) DEFAULT 0.000, @@ -212,7 +227,9 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate = 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 + CASE WHEN o.date_cancelled != '0000-00-00 00:00:00' THEN 1 ELSE 0 END as canceled, + o.summary_discount, + o.summary_subtotal FROM _order o LEFT JOIN users u ON o.order_cid = u.cid WHERE o.order_id IN (?) @@ -226,19 +243,37 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate = console.log('Found duplicates:', duplicates); } - const placeholders = orders.map(() => "(?, ?, ?, ?, ?, ?)").join(","); + const placeholders = orders.map(() => "(?, ?, ?, ?, ?, ?, ?, ?)").join(","); const values = orders.flatMap(order => [ - order.order_id, order.date, order.customer, order.customer_name, order.status, order.canceled + order.order_id, + order.date, + order.customer, + order.customer_name, + order.status, + order.canceled, + order.summary_discount, + order.summary_subtotal ]); await localConnection.query(` - INSERT INTO temp_order_meta VALUES ${placeholders} + INSERT INTO temp_order_meta ( + order_id, + date, + customer, + customer_name, + status, + canceled, + summary_discount, + summary_subtotal + ) VALUES ${placeholders} ON DUPLICATE KEY UPDATE date = VALUES(date), customer = VALUES(customer), customer_name = VALUES(customer_name), status = VALUES(status), - canceled = VALUES(canceled) + canceled = VALUES(canceled), + summary_discount = VALUES(summary_discount), + summary_subtotal = VALUES(summary_subtotal) `, values); processedCount = i + orders.length; @@ -368,9 +403,9 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate = oi.quantity, oi.base_discount + COALESCE(od.discount, 0) + CASE - WHEN o.summary_discount > 0 THEN - ROUND((o.summary_discount * (oi.price * oi.quantity)) / - NULLIF(o.summary_subtotal, 0), 2) + WHEN om.summary_discount > 0 THEN + ROUND((om.summary_discount * (oi.price * oi.quantity)) / + NULLIF(om.summary_subtotal, 0), 2) ELSE 0 END as discount, COALESCE(ot.tax, 0) as tax, @@ -383,7 +418,6 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate = COALESCE(tc.costeach, 0) as costeach FROM temp_order_items oi JOIN temp_order_meta om ON oi.order_id = om.order_id - LEFT JOIN _order o ON oi.order_id = o.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 LEFT JOIN temp_order_costs tc ON oi.order_id = tc.order_id AND oi.pid = tc.pid diff --git a/inventory-server/scripts/import/products.js b/inventory-server/scripts/import/products.js index b35364c..094808b 100644 --- a/inventory-server/scripts/import/products.js +++ b/inventory-server/scripts/import/products.js @@ -506,14 +506,18 @@ async function importProducts(prodConnection, localConnection, incrementalUpdate JOIN category_hierarchy ch ON c.parent_id = ch.cat_id WHERE ch.level < 10 -- Prevent infinite recursion ) - SELECT DISTINCT - cat_id, - parent_id, - type, - path - FROM category_hierarchy - WHERE cat_id IN (?) - ORDER BY level DESC + SELECT + h.cat_id, + h.parent_id, + h.type, + h.path, + h.level + FROM ( + SELECT DISTINCT cat_id, parent_id, type, path, level + FROM category_hierarchy + WHERE cat_id IN (?) + ) h + ORDER BY h.level DESC `, [allCategoryIds, allCategoryIds]); const validCategories = new Map(categories.map(c => [c.cat_id, c]));