Fix more import script bugs/missing data
This commit is contained in:
@@ -206,6 +206,14 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
|
||||
const METADATA_BATCH_SIZE = 2000;
|
||||
const PG_BATCH_SIZE = 200;
|
||||
|
||||
// Add a helper function for title case conversion
|
||||
function toTitleCase(str) {
|
||||
if (!str) return '';
|
||||
return str.toLowerCase().split(' ').map(word => {
|
||||
return word.charAt(0).toUpperCase() + word.slice(1);
|
||||
}).join(' ');
|
||||
}
|
||||
|
||||
const processMetadataBatch = async (batchIds) => {
|
||||
const [orders] = await prodConnection.query(`
|
||||
SELECT
|
||||
@@ -235,7 +243,7 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
|
||||
order.order_id,
|
||||
order.date,
|
||||
order.customer,
|
||||
order.customer_name || '',
|
||||
toTitleCase(order.customer_name) || '',
|
||||
order.status,
|
||||
order.canceled,
|
||||
order.summary_discount || 0,
|
||||
@@ -429,11 +437,12 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
|
||||
oi.pid,
|
||||
SUM(COALESCE(od.discount, 0)) as promo_discount,
|
||||
COALESCE(ot.tax, 0) as total_tax,
|
||||
COALESCE(oi.price * 0.5, 0) as costeach
|
||||
COALESCE(oc.costeach, oi.price * 0.5) as costeach
|
||||
FROM temp_order_items oi
|
||||
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
|
||||
GROUP BY oi.order_id, oi.pid, ot.tax
|
||||
LEFT JOIN temp_order_costs oc ON oi.order_id = oc.order_id AND oi.pid = oc.pid
|
||||
GROUP BY oi.order_id, oi.pid, ot.tax, oc.costeach
|
||||
)
|
||||
SELECT
|
||||
oi.order_id as order_number,
|
||||
@@ -491,8 +500,8 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
|
||||
const subBatch = validOrders.slice(k, k + FINAL_BATCH_SIZE);
|
||||
|
||||
const placeholders = subBatch.map((_, idx) => {
|
||||
const base = idx * 14; // 14 columns (removed updated)
|
||||
return `($${base + 1}, $${base + 2}, $${base + 3}, $${base + 4}, $${base + 5}, $${base + 6}, $${base + 7}, $${base + 8}, $${base + 9}, $${base + 10}, $${base + 11}, $${base + 12}, $${base + 13}, $${base + 14})`;
|
||||
const base = idx * 15; // 15 columns including costeach
|
||||
return `($${base + 1}, $${base + 2}, $${base + 3}, $${base + 4}, $${base + 5}, $${base + 6}, $${base + 7}, $${base + 8}, $${base + 9}, $${base + 10}, $${base + 11}, $${base + 12}, $${base + 13}, $${base + 14}, $${base + 15})`;
|
||||
}).join(',');
|
||||
|
||||
const batchValues = subBatch.flatMap(o => [
|
||||
@@ -509,7 +518,8 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
|
||||
o.customer,
|
||||
o.customer_name,
|
||||
o.status,
|
||||
o.canceled
|
||||
o.canceled,
|
||||
o.costeach
|
||||
]);
|
||||
|
||||
const [result] = await localConnection.query(`
|
||||
@@ -517,7 +527,7 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
|
||||
INSERT INTO orders (
|
||||
order_number, pid, sku, date, price, quantity, discount,
|
||||
tax, tax_included, shipping, customer, customer_name,
|
||||
status, canceled
|
||||
status, canceled, costeach
|
||||
)
|
||||
VALUES ${placeholders}
|
||||
ON CONFLICT (order_number, pid) DO UPDATE SET
|
||||
@@ -532,7 +542,8 @@ async function importOrders(prodConnection, localConnection, incrementalUpdate =
|
||||
customer = EXCLUDED.customer,
|
||||
customer_name = EXCLUDED.customer_name,
|
||||
status = EXCLUDED.status,
|
||||
canceled = EXCLUDED.canceled
|
||||
canceled = EXCLUDED.canceled,
|
||||
costeach = EXCLUDED.costeach
|
||||
RETURNING xmax = 0 as inserted
|
||||
)
|
||||
SELECT
|
||||
|
||||
@@ -1,5 +1,5 @@
|
||||
const { outputProgress, formatElapsedTime, estimateRemaining, calculateRate } = require('../metrics/utils/progress');
|
||||
const BATCH_SIZE = 100; // Smaller batch size for better progress tracking
|
||||
const BATCH_SIZE = 1000; // Smaller batch size for better progress tracking
|
||||
const MAX_RETRIES = 3;
|
||||
const RETRY_DELAY = 5000; // 5 seconds
|
||||
const dotenv = require("dotenv");
|
||||
|
||||
@@ -519,217 +519,276 @@ async function importPurchaseOrders(prodConnection, localConnection, incremental
|
||||
outputProgress({
|
||||
status: "running",
|
||||
operation: "Purchase orders import",
|
||||
message: "Allocating receivings to purchase orders using FIFO"
|
||||
message: "Validating product IDs before allocation"
|
||||
});
|
||||
|
||||
// Step 1: Handle receivings with matching PO IDs (direct allocation)
|
||||
// Add this section to filter out invalid PIDs before allocation
|
||||
// This will check all PIDs in our temp tables against the products table
|
||||
await localConnection.query(`
|
||||
INSERT INTO temp_receiving_allocations (
|
||||
po_id, pid, receiving_id, allocated_qty, cost_each, received_date, received_by
|
||||
)
|
||||
SELECT
|
||||
r.po_id,
|
||||
r.pid,
|
||||
r.receiving_id,
|
||||
LEAST(r.qty_each, po.ordered) as allocated_qty,
|
||||
r.cost_each,
|
||||
COALESCE(r.received_date, NOW()) as received_date,
|
||||
r.received_by
|
||||
FROM temp_receivings r
|
||||
JOIN temp_purchase_orders po ON r.po_id = po.po_id AND r.pid = po.pid
|
||||
WHERE r.po_id IS NOT NULL
|
||||
-- Create temp table to store invalid PIDs
|
||||
DROP TABLE IF EXISTS temp_invalid_pids;
|
||||
CREATE TEMP TABLE temp_invalid_pids AS (
|
||||
-- Get all unique PIDs from our temp tables
|
||||
WITH all_pids AS (
|
||||
SELECT DISTINCT pid FROM temp_purchase_orders
|
||||
UNION
|
||||
SELECT DISTINCT pid FROM temp_receivings
|
||||
)
|
||||
-- Filter to only those that don't exist in products table
|
||||
SELECT p.pid
|
||||
FROM all_pids p
|
||||
WHERE NOT EXISTS (
|
||||
SELECT 1 FROM products WHERE pid = p.pid
|
||||
)
|
||||
);
|
||||
|
||||
-- Remove purchase orders with invalid PIDs
|
||||
DELETE FROM temp_purchase_orders
|
||||
WHERE pid IN (SELECT pid FROM temp_invalid_pids);
|
||||
|
||||
-- Remove receivings with invalid PIDs
|
||||
DELETE FROM temp_receivings
|
||||
WHERE pid IN (SELECT pid FROM temp_invalid_pids);
|
||||
`);
|
||||
|
||||
// Step 2: Handle receivings without a matching PO (standalone receivings)
|
||||
// Create a PO entry for each standalone receiving
|
||||
await localConnection.query(`
|
||||
INSERT INTO temp_purchase_orders (
|
||||
po_id, pid, sku, name, vendor, date, status, status_text,
|
||||
ordered, po_cost_price, supplier_id, date_created, date_ordered
|
||||
)
|
||||
SELECT
|
||||
'R' || r.receiving_id as po_id,
|
||||
r.pid,
|
||||
COALESCE(p.sku, 'NO-SKU') as sku,
|
||||
COALESCE(p.name, 'Unknown Product') as name,
|
||||
COALESCE(
|
||||
(SELECT vendor FROM temp_purchase_orders
|
||||
WHERE supplier_id = r.supplier_id LIMIT 1),
|
||||
'Unknown Vendor'
|
||||
) as vendor,
|
||||
COALESCE(r.received_date, r.receiving_created_date) as date,
|
||||
NULL as status,
|
||||
NULL as status_text,
|
||||
NULL as ordered,
|
||||
r.cost_each as po_cost_price,
|
||||
r.supplier_id,
|
||||
COALESCE(r.receiving_created_date, r.received_date) as date_created,
|
||||
NULL as date_ordered
|
||||
FROM temp_receivings r
|
||||
LEFT JOIN (
|
||||
SELECT DISTINCT pid, sku, name FROM temp_purchase_orders
|
||||
) p ON r.pid = p.pid
|
||||
WHERE r.po_id IS NULL
|
||||
OR NOT EXISTS (
|
||||
SELECT 1 FROM temp_purchase_orders po
|
||||
WHERE po.po_id = r.po_id AND po.pid = r.pid
|
||||
)
|
||||
ON CONFLICT (po_id, pid) DO NOTHING
|
||||
// Get count of filtered items for reporting
|
||||
const [filteredResult] = await localConnection.query(`
|
||||
SELECT COUNT(*) as count FROM temp_invalid_pids
|
||||
`);
|
||||
const filteredCount = filteredResult.rows[0].count;
|
||||
|
||||
// Now allocate these standalone receivings to their "virtual" POs
|
||||
await localConnection.query(`
|
||||
INSERT INTO temp_receiving_allocations (
|
||||
po_id, pid, receiving_id, allocated_qty, cost_each, received_date, received_by
|
||||
)
|
||||
SELECT
|
||||
'R' || r.receiving_id as po_id,
|
||||
r.pid,
|
||||
r.receiving_id,
|
||||
r.qty_each as allocated_qty,
|
||||
r.cost_each,
|
||||
COALESCE(r.received_date, NOW()) as received_date,
|
||||
r.received_by
|
||||
FROM temp_receivings r
|
||||
WHERE r.po_id IS NULL
|
||||
OR NOT EXISTS (
|
||||
SELECT 1 FROM temp_purchase_orders po
|
||||
WHERE po.po_id = r.po_id AND po.pid = r.pid
|
||||
)
|
||||
`);
|
||||
if (filteredCount > 0) {
|
||||
console.log(`Filtered out ${filteredCount} items with invalid product IDs`);
|
||||
}
|
||||
|
||||
// Step 3: Handle unallocated receivings vs. unfulfilled orders
|
||||
// This is the complex FIFO allocation logic
|
||||
await localConnection.query(`
|
||||
WITH
|
||||
-- Calculate remaining quantities after direct allocations
|
||||
remaining_po_quantities AS (
|
||||
SELECT
|
||||
po.po_id,
|
||||
po.pid,
|
||||
po.ordered,
|
||||
COALESCE(SUM(ra.allocated_qty), 0) as already_allocated,
|
||||
po.ordered - COALESCE(SUM(ra.allocated_qty), 0) as remaining_qty,
|
||||
po.date_ordered,
|
||||
po.date_created
|
||||
FROM temp_purchase_orders po
|
||||
LEFT JOIN temp_receiving_allocations ra ON po.po_id = ra.po_id AND po.pid = ra.pid
|
||||
WHERE po.ordered IS NOT NULL
|
||||
GROUP BY po.po_id, po.pid, po.ordered, po.date_ordered, po.date_created
|
||||
HAVING po.ordered > COALESCE(SUM(ra.allocated_qty), 0)
|
||||
),
|
||||
remaining_receiving_quantities AS (
|
||||
SELECT
|
||||
r.receiving_id,
|
||||
r.pid,
|
||||
r.qty_each,
|
||||
COALESCE(SUM(ra.allocated_qty), 0) as already_allocated,
|
||||
r.qty_each - COALESCE(SUM(ra.allocated_qty), 0) as remaining_qty,
|
||||
r.received_date,
|
||||
r.cost_each,
|
||||
r.received_by
|
||||
FROM temp_receivings r
|
||||
LEFT JOIN temp_receiving_allocations ra ON r.receiving_id = ra.receiving_id AND r.pid = ra.pid
|
||||
GROUP BY r.receiving_id, r.pid, r.qty_each, r.received_date, r.cost_each, r.received_by
|
||||
HAVING r.qty_each > COALESCE(SUM(ra.allocated_qty), 0)
|
||||
),
|
||||
-- Rank POs by age, with a cutoff for very old POs (1 year)
|
||||
ranked_pos AS (
|
||||
SELECT
|
||||
po.po_id,
|
||||
po.pid,
|
||||
po.remaining_qty,
|
||||
CASE
|
||||
WHEN po.date_ordered IS NULL OR po.date_ordered < NOW() - INTERVAL '1 year' THEN 2
|
||||
ELSE 1
|
||||
END as age_group,
|
||||
ROW_NUMBER() OVER (
|
||||
PARTITION BY po.pid, (CASE WHEN po.date_ordered IS NULL OR po.date_ordered < NOW() - INTERVAL '1 year' THEN 2 ELSE 1 END)
|
||||
ORDER BY COALESCE(po.date_ordered, po.date_created, NOW())
|
||||
) as rank_in_group
|
||||
FROM remaining_po_quantities po
|
||||
),
|
||||
-- Rank receivings by date
|
||||
ranked_receivings AS (
|
||||
SELECT
|
||||
r.receiving_id,
|
||||
r.pid,
|
||||
r.remaining_qty,
|
||||
r.received_date,
|
||||
r.cost_each,
|
||||
r.received_by,
|
||||
ROW_NUMBER() OVER (PARTITION BY r.pid ORDER BY COALESCE(r.received_date, NOW())) as rank
|
||||
FROM remaining_receiving_quantities r
|
||||
),
|
||||
-- First allocate to recent POs
|
||||
allocations_recent AS (
|
||||
SELECT
|
||||
po.po_id,
|
||||
po.pid,
|
||||
r.receiving_id,
|
||||
LEAST(po.remaining_qty, r.remaining_qty) as allocated_qty,
|
||||
r.cost_each,
|
||||
COALESCE(r.received_date, NOW()) as received_date,
|
||||
r.received_by,
|
||||
po.age_group,
|
||||
po.rank_in_group,
|
||||
r.rank,
|
||||
'recent' as allocation_type
|
||||
FROM ranked_pos po
|
||||
JOIN ranked_receivings r ON po.pid = r.pid
|
||||
WHERE po.age_group = 1
|
||||
ORDER BY po.pid, po.rank_in_group, r.rank
|
||||
),
|
||||
-- Then allocate to older POs
|
||||
remaining_after_recent AS (
|
||||
SELECT
|
||||
r.receiving_id,
|
||||
r.pid,
|
||||
r.remaining_qty - COALESCE(SUM(a.allocated_qty), 0) as remaining_qty,
|
||||
r.received_date,
|
||||
r.cost_each,
|
||||
r.received_by,
|
||||
r.rank
|
||||
FROM ranked_receivings r
|
||||
LEFT JOIN allocations_recent a ON r.receiving_id = a.receiving_id AND r.pid = a.pid
|
||||
GROUP BY r.receiving_id, r.pid, r.remaining_qty, r.received_date, r.cost_each, r.received_by, r.rank
|
||||
HAVING r.remaining_qty > COALESCE(SUM(a.allocated_qty), 0)
|
||||
),
|
||||
allocations_old AS (
|
||||
SELECT
|
||||
po.po_id,
|
||||
po.pid,
|
||||
r.receiving_id,
|
||||
LEAST(po.remaining_qty, r.remaining_qty) as allocated_qty,
|
||||
r.cost_each,
|
||||
COALESCE(r.received_date, NOW()) as received_date,
|
||||
r.received_by,
|
||||
po.age_group,
|
||||
po.rank_in_group,
|
||||
r.rank,
|
||||
'old' as allocation_type
|
||||
FROM ranked_pos po
|
||||
JOIN remaining_after_recent r ON po.pid = r.pid
|
||||
WHERE po.age_group = 2
|
||||
ORDER BY po.pid, po.rank_in_group, r.rank
|
||||
),
|
||||
-- Combine allocations
|
||||
combined_allocations AS (
|
||||
SELECT * FROM allocations_recent
|
||||
UNION ALL
|
||||
SELECT * FROM allocations_old
|
||||
)
|
||||
-- Insert into allocations table
|
||||
INSERT INTO temp_receiving_allocations (
|
||||
po_id, pid, receiving_id, allocated_qty, cost_each, received_date, received_by
|
||||
)
|
||||
SELECT
|
||||
po_id, pid, receiving_id, allocated_qty, cost_each,
|
||||
COALESCE(received_date, NOW()) as received_date,
|
||||
received_by
|
||||
FROM combined_allocations
|
||||
WHERE allocated_qty > 0
|
||||
`);
|
||||
// Break FIFO allocation into steps with progress tracking
|
||||
const fifoSteps = [
|
||||
{
|
||||
name: "Direct allocations",
|
||||
query: `
|
||||
INSERT INTO temp_receiving_allocations (
|
||||
po_id, pid, receiving_id, allocated_qty, cost_each, received_date, received_by
|
||||
)
|
||||
SELECT
|
||||
r.po_id,
|
||||
r.pid,
|
||||
r.receiving_id,
|
||||
LEAST(r.qty_each, po.ordered) as allocated_qty,
|
||||
r.cost_each,
|
||||
COALESCE(r.received_date, NOW()) as received_date,
|
||||
r.received_by
|
||||
FROM temp_receivings r
|
||||
JOIN temp_purchase_orders po ON r.po_id = po.po_id AND r.pid = po.pid
|
||||
WHERE r.po_id IS NOT NULL
|
||||
`
|
||||
},
|
||||
{
|
||||
name: "Handling standalone receivings",
|
||||
query: `
|
||||
INSERT INTO temp_purchase_orders (
|
||||
po_id, pid, sku, name, vendor, date, status, status_text,
|
||||
ordered, po_cost_price, supplier_id, date_created, date_ordered
|
||||
)
|
||||
SELECT
|
||||
'R' || r.receiving_id as po_id,
|
||||
r.pid,
|
||||
COALESCE(p.sku, 'NO-SKU') as sku,
|
||||
COALESCE(p.name, 'Unknown Product') as name,
|
||||
COALESCE(
|
||||
(SELECT vendor FROM temp_purchase_orders
|
||||
WHERE supplier_id = r.supplier_id LIMIT 1),
|
||||
'Unknown Vendor'
|
||||
) as vendor,
|
||||
COALESCE(r.received_date, r.receiving_created_date) as date,
|
||||
NULL as status,
|
||||
NULL as status_text,
|
||||
NULL as ordered,
|
||||
r.cost_each as po_cost_price,
|
||||
r.supplier_id,
|
||||
COALESCE(r.receiving_created_date, r.received_date) as date_created,
|
||||
NULL as date_ordered
|
||||
FROM temp_receivings r
|
||||
LEFT JOIN (
|
||||
SELECT DISTINCT pid, sku, name FROM temp_purchase_orders
|
||||
) p ON r.pid = p.pid
|
||||
WHERE r.po_id IS NULL
|
||||
OR NOT EXISTS (
|
||||
SELECT 1 FROM temp_purchase_orders po
|
||||
WHERE po.po_id = r.po_id AND po.pid = r.pid
|
||||
)
|
||||
ON CONFLICT (po_id, pid) DO NOTHING
|
||||
`
|
||||
},
|
||||
{
|
||||
name: "Allocating standalone receivings",
|
||||
query: `
|
||||
INSERT INTO temp_receiving_allocations (
|
||||
po_id, pid, receiving_id, allocated_qty, cost_each, received_date, received_by
|
||||
)
|
||||
SELECT
|
||||
'R' || r.receiving_id as po_id,
|
||||
r.pid,
|
||||
r.receiving_id,
|
||||
r.qty_each as allocated_qty,
|
||||
r.cost_each,
|
||||
COALESCE(r.received_date, NOW()) as received_date,
|
||||
r.received_by
|
||||
FROM temp_receivings r
|
||||
WHERE r.po_id IS NULL
|
||||
OR NOT EXISTS (
|
||||
SELECT 1 FROM temp_purchase_orders po
|
||||
WHERE po.po_id = r.po_id AND po.pid = r.pid
|
||||
)
|
||||
`
|
||||
},
|
||||
{
|
||||
name: "FIFO allocation logic",
|
||||
query: `
|
||||
WITH
|
||||
-- Calculate remaining quantities after direct allocations
|
||||
remaining_po_quantities AS (
|
||||
SELECT
|
||||
po.po_id,
|
||||
po.pid,
|
||||
po.ordered,
|
||||
COALESCE(SUM(ra.allocated_qty), 0) as already_allocated,
|
||||
po.ordered - COALESCE(SUM(ra.allocated_qty), 0) as remaining_qty,
|
||||
po.date_ordered,
|
||||
po.date_created
|
||||
FROM temp_purchase_orders po
|
||||
LEFT JOIN temp_receiving_allocations ra ON po.po_id = ra.po_id AND po.pid = ra.pid
|
||||
WHERE po.ordered IS NOT NULL
|
||||
GROUP BY po.po_id, po.pid, po.ordered, po.date_ordered, po.date_created
|
||||
HAVING po.ordered > COALESCE(SUM(ra.allocated_qty), 0)
|
||||
),
|
||||
remaining_receiving_quantities AS (
|
||||
SELECT
|
||||
r.receiving_id,
|
||||
r.pid,
|
||||
r.qty_each,
|
||||
COALESCE(SUM(ra.allocated_qty), 0) as already_allocated,
|
||||
r.qty_each - COALESCE(SUM(ra.allocated_qty), 0) as remaining_qty,
|
||||
r.received_date,
|
||||
r.cost_each,
|
||||
r.received_by
|
||||
FROM temp_receivings r
|
||||
LEFT JOIN temp_receiving_allocations ra ON r.receiving_id = ra.receiving_id AND r.pid = ra.pid
|
||||
GROUP BY r.receiving_id, r.pid, r.qty_each, r.received_date, r.cost_each, r.received_by
|
||||
HAVING r.qty_each > COALESCE(SUM(ra.allocated_qty), 0)
|
||||
),
|
||||
-- Rank POs by age, with a cutoff for very old POs (1 year)
|
||||
ranked_pos AS (
|
||||
SELECT
|
||||
po.po_id,
|
||||
po.pid,
|
||||
po.remaining_qty,
|
||||
CASE
|
||||
WHEN po.date_ordered IS NULL OR po.date_ordered < NOW() - INTERVAL '1 year' THEN 2
|
||||
ELSE 1
|
||||
END as age_group,
|
||||
ROW_NUMBER() OVER (
|
||||
PARTITION BY po.pid, (CASE WHEN po.date_ordered IS NULL OR po.date_ordered < NOW() - INTERVAL '1 year' THEN 2 ELSE 1 END)
|
||||
ORDER BY COALESCE(po.date_ordered, po.date_created, NOW())
|
||||
) as rank_in_group
|
||||
FROM remaining_po_quantities po
|
||||
),
|
||||
-- Rank receivings by date
|
||||
ranked_receivings AS (
|
||||
SELECT
|
||||
r.receiving_id,
|
||||
r.pid,
|
||||
r.remaining_qty,
|
||||
r.received_date,
|
||||
r.cost_each,
|
||||
r.received_by,
|
||||
ROW_NUMBER() OVER (PARTITION BY r.pid ORDER BY COALESCE(r.received_date, NOW())) as rank
|
||||
FROM remaining_receiving_quantities r
|
||||
),
|
||||
-- First allocate to recent POs
|
||||
allocations_recent AS (
|
||||
SELECT
|
||||
po.po_id,
|
||||
po.pid,
|
||||
r.receiving_id,
|
||||
LEAST(po.remaining_qty, r.remaining_qty) as allocated_qty,
|
||||
r.cost_each,
|
||||
COALESCE(r.received_date, NOW()) as received_date,
|
||||
r.received_by,
|
||||
po.age_group,
|
||||
po.rank_in_group,
|
||||
r.rank,
|
||||
'recent' as allocation_type
|
||||
FROM ranked_pos po
|
||||
JOIN ranked_receivings r ON po.pid = r.pid
|
||||
WHERE po.age_group = 1
|
||||
ORDER BY po.pid, po.rank_in_group, r.rank
|
||||
),
|
||||
-- Then allocate to older POs
|
||||
remaining_after_recent AS (
|
||||
SELECT
|
||||
r.receiving_id,
|
||||
r.pid,
|
||||
r.remaining_qty - COALESCE(SUM(a.allocated_qty), 0) as remaining_qty,
|
||||
r.received_date,
|
||||
r.cost_each,
|
||||
r.received_by,
|
||||
r.rank
|
||||
FROM ranked_receivings r
|
||||
LEFT JOIN allocations_recent a ON r.receiving_id = a.receiving_id AND r.pid = a.pid
|
||||
GROUP BY r.receiving_id, r.pid, r.remaining_qty, r.received_date, r.cost_each, r.received_by, r.rank
|
||||
HAVING r.remaining_qty > COALESCE(SUM(a.allocated_qty), 0)
|
||||
),
|
||||
allocations_old AS (
|
||||
SELECT
|
||||
po.po_id,
|
||||
po.pid,
|
||||
r.receiving_id,
|
||||
LEAST(po.remaining_qty, r.remaining_qty) as allocated_qty,
|
||||
r.cost_each,
|
||||
COALESCE(r.received_date, NOW()) as received_date,
|
||||
r.received_by,
|
||||
po.age_group,
|
||||
po.rank_in_group,
|
||||
r.rank,
|
||||
'old' as allocation_type
|
||||
FROM ranked_pos po
|
||||
JOIN remaining_after_recent r ON po.pid = r.pid
|
||||
WHERE po.age_group = 2
|
||||
ORDER BY po.pid, po.rank_in_group, r.rank
|
||||
),
|
||||
-- Combine allocations
|
||||
combined_allocations AS (
|
||||
SELECT * FROM allocations_recent
|
||||
UNION ALL
|
||||
SELECT * FROM allocations_old
|
||||
)
|
||||
-- Insert into allocations table
|
||||
INSERT INTO temp_receiving_allocations (
|
||||
po_id, pid, receiving_id, allocated_qty, cost_each, received_date, received_by
|
||||
)
|
||||
SELECT
|
||||
po_id, pid, receiving_id, allocated_qty, cost_each,
|
||||
COALESCE(received_date, NOW()) as received_date,
|
||||
received_by
|
||||
FROM combined_allocations
|
||||
WHERE allocated_qty > 0
|
||||
`
|
||||
}
|
||||
];
|
||||
|
||||
// Execute FIFO steps with progress tracking
|
||||
for (let i = 0; i < fifoSteps.length; i++) {
|
||||
const step = fifoSteps[i];
|
||||
outputProgress({
|
||||
status: "running",
|
||||
operation: "Purchase orders import",
|
||||
message: `FIFO allocation step ${i+1}/${fifoSteps.length}: ${step.name}`,
|
||||
current: i,
|
||||
total: fifoSteps.length
|
||||
});
|
||||
|
||||
await localConnection.query(step.query);
|
||||
}
|
||||
|
||||
// 4. Generate final purchase order records with receiving data
|
||||
outputProgress({
|
||||
|
||||
Reference in New Issue
Block a user