UI tweaks for match columns step + auto hide empty columns
This commit is contained in:
@@ -1,344 +0,0 @@
|
||||
const { outputProgress, formatElapsedTime, estimateRemaining, calculateRate, logError } = require('./utils/progress');
|
||||
const { getConnection } = require('./utils/db');
|
||||
|
||||
async function calculateTimeAggregates(startTime, totalProducts, processedCount = 0, isCancelled = false) {
|
||||
const connection = await getConnection();
|
||||
let success = false;
|
||||
let processedOrders = 0;
|
||||
|
||||
try {
|
||||
if (isCancelled) {
|
||||
outputProgress({
|
||||
status: 'cancelled',
|
||||
operation: 'Time aggregates calculation cancelled',
|
||||
current: processedCount,
|
||||
total: totalProducts,
|
||||
elapsed: formatElapsedTime(startTime),
|
||||
remaining: null,
|
||||
rate: calculateRate(startTime, processedCount),
|
||||
percentage: ((processedCount / totalProducts) * 100).toFixed(1),
|
||||
timing: {
|
||||
start_time: new Date(startTime).toISOString(),
|
||||
end_time: new Date().toISOString(),
|
||||
elapsed_seconds: Math.round((Date.now() - startTime) / 1000)
|
||||
}
|
||||
});
|
||||
return {
|
||||
processedProducts: processedCount,
|
||||
processedOrders: 0,
|
||||
processedPurchaseOrders: 0,
|
||||
success
|
||||
};
|
||||
}
|
||||
|
||||
// Get order count that will be processed
|
||||
const orderCount = await connection.query(`
|
||||
SELECT COUNT(*) as count
|
||||
FROM orders o
|
||||
WHERE o.canceled = false
|
||||
`);
|
||||
processedOrders = parseInt(orderCount.rows[0].count);
|
||||
|
||||
outputProgress({
|
||||
status: 'running',
|
||||
operation: 'Starting time aggregates calculation',
|
||||
current: processedCount,
|
||||
total: totalProducts,
|
||||
elapsed: formatElapsedTime(startTime),
|
||||
remaining: estimateRemaining(startTime, processedCount, totalProducts),
|
||||
rate: calculateRate(startTime, processedCount),
|
||||
percentage: ((processedCount / totalProducts) * 100).toFixed(1),
|
||||
timing: {
|
||||
start_time: new Date(startTime).toISOString(),
|
||||
end_time: new Date().toISOString(),
|
||||
elapsed_seconds: Math.round((Date.now() - startTime) / 1000)
|
||||
}
|
||||
});
|
||||
|
||||
// Create a temporary table for end-of-month inventory values
|
||||
await connection.query(`
|
||||
CREATE TEMPORARY TABLE IF NOT EXISTS temp_monthly_inventory AS
|
||||
WITH months AS (
|
||||
-- Generate all year/month combinations for the last 12 months
|
||||
SELECT
|
||||
EXTRACT(YEAR FROM month_date)::INTEGER as year,
|
||||
EXTRACT(MONTH FROM month_date)::INTEGER as month,
|
||||
month_date as start_date,
|
||||
(month_date + INTERVAL '1 month'::interval - INTERVAL '1 day'::interval)::DATE as end_date
|
||||
FROM (
|
||||
SELECT generate_series(
|
||||
DATE_TRUNC('month', CURRENT_DATE - INTERVAL '12 months'::interval)::DATE,
|
||||
DATE_TRUNC('month', CURRENT_DATE)::DATE,
|
||||
INTERVAL '1 month'::interval
|
||||
) as month_date
|
||||
) dates
|
||||
),
|
||||
monthly_inventory_calc AS (
|
||||
SELECT
|
||||
p.pid,
|
||||
m.year,
|
||||
m.month,
|
||||
m.end_date,
|
||||
p.stock_quantity as current_quantity,
|
||||
-- Calculate sold during period (before end_date)
|
||||
COALESCE(SUM(
|
||||
CASE
|
||||
WHEN o.date <= m.end_date THEN o.quantity
|
||||
ELSE 0
|
||||
END
|
||||
), 0) as sold_after_end_date,
|
||||
-- Calculate received during period (before end_date)
|
||||
COALESCE(SUM(
|
||||
CASE
|
||||
WHEN po.received_date <= m.end_date THEN po.received
|
||||
ELSE 0
|
||||
END
|
||||
), 0) as received_after_end_date,
|
||||
p.cost_price
|
||||
FROM
|
||||
products p
|
||||
CROSS JOIN
|
||||
months m
|
||||
LEFT JOIN
|
||||
orders o ON p.pid = o.pid
|
||||
AND o.canceled = false
|
||||
AND o.date > m.end_date
|
||||
AND o.date <= CURRENT_DATE
|
||||
LEFT JOIN
|
||||
purchase_orders po ON p.pid = po.pid
|
||||
AND po.received_date IS NOT NULL
|
||||
AND po.received_date > m.end_date
|
||||
AND po.received_date <= CURRENT_DATE
|
||||
GROUP BY
|
||||
p.pid, m.year, m.month, m.end_date, p.stock_quantity, p.cost_price
|
||||
)
|
||||
SELECT
|
||||
pid,
|
||||
year,
|
||||
month,
|
||||
-- End of month quantity = current quantity - sold after + received after
|
||||
GREATEST(0, current_quantity - sold_after_end_date + received_after_end_date) as end_of_month_quantity,
|
||||
-- End of month inventory value
|
||||
GREATEST(0, current_quantity - sold_after_end_date + received_after_end_date) * cost_price as end_of_month_value,
|
||||
cost_price
|
||||
FROM
|
||||
monthly_inventory_calc
|
||||
`);
|
||||
|
||||
processedCount = Math.floor(totalProducts * 0.40);
|
||||
outputProgress({
|
||||
status: 'running',
|
||||
operation: 'Monthly inventory values calculated, processing time aggregates',
|
||||
current: processedCount,
|
||||
total: totalProducts,
|
||||
elapsed: formatElapsedTime(startTime),
|
||||
remaining: estimateRemaining(startTime, processedCount, totalProducts),
|
||||
rate: calculateRate(startTime, processedCount),
|
||||
percentage: ((processedCount / totalProducts) * 100).toFixed(1),
|
||||
timing: {
|
||||
start_time: new Date(startTime).toISOString(),
|
||||
end_time: new Date().toISOString(),
|
||||
elapsed_seconds: Math.round((Date.now() - startTime) / 1000)
|
||||
}
|
||||
});
|
||||
|
||||
// Initial insert of time-based aggregates
|
||||
await connection.query(`
|
||||
INSERT INTO product_time_aggregates (
|
||||
pid,
|
||||
year,
|
||||
month,
|
||||
total_quantity_sold,
|
||||
total_revenue,
|
||||
total_cost,
|
||||
order_count,
|
||||
stock_received,
|
||||
stock_ordered,
|
||||
avg_price,
|
||||
profit_margin,
|
||||
inventory_value,
|
||||
gmroi
|
||||
)
|
||||
WITH monthly_sales AS (
|
||||
SELECT
|
||||
o.pid,
|
||||
EXTRACT(YEAR FROM o.date::timestamp with time zone)::INTEGER as year,
|
||||
EXTRACT(MONTH FROM o.date::timestamp with time zone)::INTEGER as month,
|
||||
SUM(o.quantity) as total_quantity_sold,
|
||||
SUM((o.price - COALESCE(o.discount, 0)) * o.quantity) as total_revenue,
|
||||
SUM(COALESCE(o.costeach, 0) * o.quantity) as total_cost,
|
||||
COUNT(DISTINCT o.order_number) as order_count,
|
||||
AVG(o.price - COALESCE(o.discount, 0)) as avg_price,
|
||||
CASE
|
||||
WHEN SUM((o.price - COALESCE(o.discount, 0)) * o.quantity) > 0
|
||||
THEN ((SUM((o.price - COALESCE(o.discount, 0)) * o.quantity) - SUM(COALESCE(o.costeach, 0) * o.quantity))
|
||||
/ SUM((o.price - COALESCE(o.discount, 0)) * o.quantity)) * 100
|
||||
ELSE 0
|
||||
END as profit_margin,
|
||||
COUNT(DISTINCT DATE(o.date)) as active_days
|
||||
FROM orders o
|
||||
JOIN products p ON o.pid = p.pid
|
||||
WHERE o.canceled = false
|
||||
GROUP BY o.pid, EXTRACT(YEAR FROM o.date::timestamp with time zone), EXTRACT(MONTH FROM o.date::timestamp with time zone)
|
||||
),
|
||||
monthly_stock AS (
|
||||
SELECT
|
||||
pid,
|
||||
EXTRACT(YEAR FROM date::timestamp with time zone)::INTEGER as year,
|
||||
EXTRACT(MONTH FROM date::timestamp with time zone)::INTEGER as month,
|
||||
SUM(received) as stock_received,
|
||||
SUM(ordered) as stock_ordered
|
||||
FROM purchase_orders
|
||||
GROUP BY pid, EXTRACT(YEAR FROM date::timestamp with time zone), EXTRACT(MONTH FROM date::timestamp with time zone)
|
||||
)
|
||||
SELECT
|
||||
COALESCE(s.pid, ms.pid, mi.pid) as pid,
|
||||
COALESCE(s.year, ms.year, mi.year) as year,
|
||||
COALESCE(s.month, ms.month, mi.month) as month,
|
||||
COALESCE(s.total_quantity_sold, 0)::INTEGER as total_quantity_sold,
|
||||
COALESCE(s.total_revenue, 0)::DECIMAL(10,3) as total_revenue,
|
||||
COALESCE(s.total_cost, 0)::DECIMAL(10,3) as total_cost,
|
||||
COALESCE(s.order_count, 0)::INTEGER as order_count,
|
||||
COALESCE(ms.stock_received, 0)::INTEGER as stock_received,
|
||||
COALESCE(ms.stock_ordered, 0)::INTEGER as stock_ordered,
|
||||
COALESCE(s.avg_price, 0)::DECIMAL(10,3) as avg_price,
|
||||
COALESCE(s.profit_margin, 0)::DECIMAL(10,3) as profit_margin,
|
||||
COALESCE(mi.end_of_month_value, 0)::DECIMAL(10,3) as inventory_value,
|
||||
CASE
|
||||
WHEN COALESCE(mi.end_of_month_value, 0) > 0
|
||||
THEN (COALESCE(s.total_revenue, 0) - COALESCE(s.total_cost, 0))
|
||||
/ NULLIF(COALESCE(mi.end_of_month_value, 0), 0)
|
||||
ELSE 0
|
||||
END::DECIMAL(10,3) as gmroi
|
||||
FROM (
|
||||
SELECT * FROM monthly_sales s
|
||||
UNION ALL
|
||||
SELECT
|
||||
pid,
|
||||
year,
|
||||
month,
|
||||
0 as total_quantity_sold,
|
||||
0 as total_revenue,
|
||||
0 as total_cost,
|
||||
0 as order_count,
|
||||
NULL as avg_price,
|
||||
0 as profit_margin,
|
||||
0 as active_days
|
||||
FROM monthly_stock ms
|
||||
WHERE NOT EXISTS (
|
||||
SELECT 1 FROM monthly_sales s2
|
||||
WHERE s2.pid = ms.pid
|
||||
AND s2.year = ms.year
|
||||
AND s2.month = ms.month
|
||||
)
|
||||
UNION ALL
|
||||
SELECT
|
||||
pid,
|
||||
year,
|
||||
month,
|
||||
0 as total_quantity_sold,
|
||||
0 as total_revenue,
|
||||
0 as total_cost,
|
||||
0 as order_count,
|
||||
NULL as avg_price,
|
||||
0 as profit_margin,
|
||||
0 as active_days
|
||||
FROM temp_monthly_inventory mi
|
||||
WHERE NOT EXISTS (
|
||||
SELECT 1 FROM monthly_sales s3
|
||||
WHERE s3.pid = mi.pid
|
||||
AND s3.year = mi.year
|
||||
AND s3.month = mi.month
|
||||
)
|
||||
AND NOT EXISTS (
|
||||
SELECT 1 FROM monthly_stock ms3
|
||||
WHERE ms3.pid = mi.pid
|
||||
AND ms3.year = mi.year
|
||||
AND ms3.month = mi.month
|
||||
)
|
||||
) s
|
||||
LEFT JOIN monthly_stock ms
|
||||
ON s.pid = ms.pid
|
||||
AND s.year = ms.year
|
||||
AND s.month = ms.month
|
||||
LEFT JOIN temp_monthly_inventory mi
|
||||
ON s.pid = mi.pid
|
||||
AND s.year = mi.year
|
||||
AND s.month = mi.month
|
||||
ON CONFLICT (pid, year, month) DO UPDATE
|
||||
SET
|
||||
total_quantity_sold = EXCLUDED.total_quantity_sold,
|
||||
total_revenue = EXCLUDED.total_revenue,
|
||||
total_cost = EXCLUDED.total_cost,
|
||||
order_count = EXCLUDED.order_count,
|
||||
stock_received = EXCLUDED.stock_received,
|
||||
stock_ordered = EXCLUDED.stock_ordered,
|
||||
avg_price = EXCLUDED.avg_price,
|
||||
profit_margin = EXCLUDED.profit_margin,
|
||||
inventory_value = EXCLUDED.inventory_value,
|
||||
gmroi = EXCLUDED.gmroi
|
||||
`);
|
||||
|
||||
processedCount = Math.floor(totalProducts * 0.60);
|
||||
outputProgress({
|
||||
status: 'running',
|
||||
operation: 'Base time aggregates calculated',
|
||||
current: processedCount,
|
||||
total: totalProducts,
|
||||
elapsed: formatElapsedTime(startTime),
|
||||
remaining: estimateRemaining(startTime, processedCount, totalProducts),
|
||||
rate: calculateRate(startTime, processedCount),
|
||||
percentage: ((processedCount / totalProducts) * 100).toFixed(1),
|
||||
timing: {
|
||||
start_time: new Date(startTime).toISOString(),
|
||||
end_time: new Date().toISOString(),
|
||||
elapsed_seconds: Math.round((Date.now() - startTime) / 1000)
|
||||
}
|
||||
});
|
||||
|
||||
if (isCancelled) return {
|
||||
processedProducts: processedCount,
|
||||
processedOrders,
|
||||
processedPurchaseOrders: 0,
|
||||
success
|
||||
};
|
||||
|
||||
// Clean up temporary tables
|
||||
await connection.query('DROP TABLE IF EXISTS temp_monthly_inventory');
|
||||
|
||||
// If we get here, everything completed successfully
|
||||
success = true;
|
||||
|
||||
// Update calculate_status
|
||||
await connection.query(`
|
||||
INSERT INTO calculate_status (module_name, last_calculation_timestamp)
|
||||
VALUES ('time_aggregates', NOW())
|
||||
ON CONFLICT (module_name) DO UPDATE
|
||||
SET last_calculation_timestamp = NOW()
|
||||
`);
|
||||
|
||||
return {
|
||||
processedProducts: processedCount,
|
||||
processedOrders,
|
||||
processedPurchaseOrders: 0,
|
||||
success
|
||||
};
|
||||
|
||||
} catch (error) {
|
||||
success = false;
|
||||
logError(error, 'Error calculating time aggregates');
|
||||
throw error;
|
||||
} finally {
|
||||
if (connection) {
|
||||
try {
|
||||
// Ensure temporary tables are cleaned up
|
||||
await connection.query('DROP TABLE IF EXISTS temp_monthly_inventory');
|
||||
} catch (err) {
|
||||
console.error('Error cleaning up temporary tables:', err);
|
||||
}
|
||||
connection.release();
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
module.exports = calculateTimeAggregates;
|
||||
Reference in New Issue
Block a user