Add new filter options and metrics to product filters and pages; enhance SQL schema for financial calculations

This commit is contained in:
2025-03-27 16:27:13 -04:00
parent 8b8845b423
commit 957c7b5eb1
17 changed files with 2216 additions and 482 deletions

View File

@@ -55,6 +55,93 @@ async function calculateTimeAggregates(startTime, totalProducts, processedCount
}
});
// 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 (
@@ -75,76 +162,67 @@ async function calculateTimeAggregates(startTime, totalProducts, processedCount
WITH monthly_sales AS (
SELECT
o.pid,
EXTRACT(YEAR FROM o.date::timestamp with time zone) as year,
EXTRACT(MONTH FROM o.date::timestamp with time zone) as month,
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(p.cost_price, 0) * o.quantity) as total_cost,
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(p.cost_price, 0) * o.quantity))
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,
p.cost_price * p.stock_quantity as inventory_value,
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), p.cost_price, p.stock_quantity
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) as year,
EXTRACT(MONTH FROM date::timestamp with time zone) as month,
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)
),
base_products AS (
SELECT
p.pid,
p.cost_price * p.stock_quantity as inventory_value
FROM products p
)
SELECT
COALESCE(s.pid, ms.pid) as pid,
COALESCE(s.year, ms.year) as year,
COALESCE(s.month, ms.month) as month,
COALESCE(s.total_quantity_sold, 0) as total_quantity_sold,
COALESCE(s.total_revenue, 0) as total_revenue,
COALESCE(s.total_cost, 0) as total_cost,
COALESCE(s.order_count, 0) as order_count,
COALESCE(ms.stock_received, 0) as stock_received,
COALESCE(ms.stock_ordered, 0) as stock_ordered,
COALESCE(s.avg_price, 0) as avg_price,
COALESCE(s.profit_margin, 0) as profit_margin,
COALESCE(s.inventory_value, bp.inventory_value, 0) as inventory_value,
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(s.inventory_value, bp.inventory_value, 0) > 0
AND COALESCE(s.active_days, 0) > 0
THEN (COALESCE(s.total_revenue - s.total_cost, 0) * (365.0 / s.active_days))
/ COALESCE(s.inventory_value, bp.inventory_value)
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 as gmroi
END::DECIMAL(10,3) as gmroi
FROM (
SELECT * FROM monthly_sales s
UNION ALL
SELECT
ms.pid,
ms.year,
ms.month,
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,
NULL as inventory_value,
0 as active_days
FROM monthly_stock ms
WHERE NOT EXISTS (
@@ -153,50 +231,40 @@ async function calculateTimeAggregates(startTime, totalProducts, processedCount
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
JOIN base_products bp ON COALESCE(s.pid, ms.pid) = bp.pid
UNION
SELECT
ms.pid,
ms.year,
ms.month,
0 as total_quantity_sold,
0 as total_revenue,
0 as total_cost,
0 as order_count,
ms.stock_received,
ms.stock_ordered,
0 as avg_price,
0 as profit_margin,
bp.inventory_value,
0 as gmroi
FROM monthly_stock ms
JOIN base_products bp ON ms.pid = bp.pid
WHERE NOT EXISTS (
SELECT 1 FROM (
SELECT * FROM monthly_sales
UNION ALL
SELECT
ms2.pid,
ms2.year,
ms2.month,
0, 0, 0, 0, NULL, 0, NULL, 0
FROM monthly_stock ms2
WHERE NOT EXISTS (
SELECT 1 FROM monthly_sales s2
WHERE s2.pid = ms2.pid
AND s2.year = ms2.year
AND s2.month = ms2.month
)
) s
WHERE 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,
@@ -214,7 +282,7 @@ async function calculateTimeAggregates(startTime, totalProducts, processedCount
processedCount = Math.floor(totalProducts * 0.60);
outputProgress({
status: 'running',
operation: 'Base time aggregates calculated, updating financial metrics',
operation: 'Base time aggregates calculated',
current: processedCount,
total: totalProducts,
elapsed: formatElapsedTime(startTime),
@@ -234,45 +302,9 @@ async function calculateTimeAggregates(startTime, totalProducts, processedCount
processedPurchaseOrders: 0,
success
};
// Update with financial metrics
await connection.query(`
UPDATE product_time_aggregates pta
SET inventory_value = COALESCE(fin.inventory_value, 0)
FROM (
SELECT
p.pid,
EXTRACT(YEAR FROM o.date::timestamp with time zone) as year,
EXTRACT(MONTH FROM o.date::timestamp with time zone) as month,
p.cost_price * p.stock_quantity as inventory_value,
SUM(o.quantity * (o.price - p.cost_price)) as gross_profit,
COUNT(DISTINCT DATE(o.date)) as active_days
FROM products p
LEFT JOIN orders o ON p.pid = o.pid
WHERE o.canceled = false
GROUP BY p.pid, EXTRACT(YEAR FROM o.date::timestamp with time zone), EXTRACT(MONTH FROM o.date::timestamp with time zone), p.cost_price, p.stock_quantity
) fin
WHERE pta.pid = fin.pid
AND pta.year = fin.year
AND pta.month = fin.month
`);
processedCount = Math.floor(totalProducts * 0.65);
outputProgress({
status: 'running',
operation: 'Financial metrics updated',
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)
}
});
// Clean up temporary tables
await connection.query('DROP TABLE IF EXISTS temp_monthly_inventory');
// If we get here, everything completed successfully
success = true;
@@ -298,6 +330,12 @@ async function calculateTimeAggregates(startTime, totalProducts, processedCount
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();
}
}