Flatten calculate file structure a bit
This commit is contained in:
133
inventory-server/scripts/metrics/time-aggregates.js
Normal file
133
inventory-server/scripts/metrics/time-aggregates.js
Normal file
@@ -0,0 +1,133 @@
|
||||
const { getConnection } = require('./db');
|
||||
|
||||
async function calculateTimeAggregates(startTime, totalProducts, processedCount) {
|
||||
const connection = await getConnection();
|
||||
try {
|
||||
// Initial insert of time-based aggregates
|
||||
await connection.query(`
|
||||
INSERT INTO product_time_aggregates (
|
||||
product_id,
|
||||
year,
|
||||
month,
|
||||
total_quantity_sold,
|
||||
total_revenue,
|
||||
total_cost,
|
||||
order_count,
|
||||
stock_received,
|
||||
stock_ordered,
|
||||
avg_price,
|
||||
profit_margin
|
||||
)
|
||||
WITH sales_data AS (
|
||||
SELECT
|
||||
o.product_id,
|
||||
YEAR(o.date) as year,
|
||||
MONTH(o.date) 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,
|
||||
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 0
|
||||
ELSE ((SUM((o.price - COALESCE(o.discount, 0)) * o.quantity) -
|
||||
SUM(COALESCE(p.cost_price, 0) * o.quantity)) /
|
||||
SUM((o.price - COALESCE(o.discount, 0)) * o.quantity)) * 100
|
||||
END as profit_margin
|
||||
FROM orders o
|
||||
JOIN products p ON o.product_id = p.product_id
|
||||
WHERE o.canceled = 0
|
||||
GROUP BY o.product_id, YEAR(o.date), MONTH(o.date)
|
||||
),
|
||||
purchase_data AS (
|
||||
SELECT
|
||||
product_id,
|
||||
YEAR(date) as year,
|
||||
MONTH(date) as month,
|
||||
SUM(received) as stock_received,
|
||||
SUM(ordered) as stock_ordered
|
||||
FROM purchase_orders
|
||||
WHERE status = 'closed'
|
||||
GROUP BY product_id, YEAR(date), MONTH(date)
|
||||
)
|
||||
SELECT
|
||||
s.product_id,
|
||||
s.year,
|
||||
s.month,
|
||||
s.total_quantity_sold,
|
||||
s.total_revenue,
|
||||
s.total_cost,
|
||||
s.order_count,
|
||||
COALESCE(p.stock_received, 0) as stock_received,
|
||||
COALESCE(p.stock_ordered, 0) as stock_ordered,
|
||||
s.avg_price,
|
||||
s.profit_margin
|
||||
FROM sales_data s
|
||||
LEFT JOIN purchase_data p
|
||||
ON s.product_id = p.product_id
|
||||
AND s.year = p.year
|
||||
AND s.month = p.month
|
||||
UNION
|
||||
SELECT
|
||||
p.product_id,
|
||||
p.year,
|
||||
p.month,
|
||||
0 as total_quantity_sold,
|
||||
0 as total_revenue,
|
||||
0 as total_cost,
|
||||
0 as order_count,
|
||||
p.stock_received,
|
||||
p.stock_ordered,
|
||||
0 as avg_price,
|
||||
0 as profit_margin
|
||||
FROM purchase_data p
|
||||
LEFT JOIN sales_data s
|
||||
ON p.product_id = s.product_id
|
||||
AND p.year = s.year
|
||||
AND p.month = s.month
|
||||
WHERE s.product_id IS NULL
|
||||
ON DUPLICATE KEY UPDATE
|
||||
total_quantity_sold = VALUES(total_quantity_sold),
|
||||
total_revenue = VALUES(total_revenue),
|
||||
total_cost = VALUES(total_cost),
|
||||
order_count = VALUES(order_count),
|
||||
stock_received = VALUES(stock_received),
|
||||
stock_ordered = VALUES(stock_ordered),
|
||||
avg_price = VALUES(avg_price),
|
||||
profit_margin = VALUES(profit_margin)
|
||||
`);
|
||||
|
||||
// Update with financial metrics
|
||||
await connection.query(`
|
||||
UPDATE product_time_aggregates pta
|
||||
JOIN (
|
||||
SELECT
|
||||
p.product_id,
|
||||
YEAR(o.date) as year,
|
||||
MONTH(o.date) 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 days_in_period
|
||||
FROM products p
|
||||
LEFT JOIN orders o ON p.product_id = o.product_id
|
||||
WHERE o.canceled = false
|
||||
GROUP BY p.product_id, YEAR(o.date), MONTH(o.date)
|
||||
) fin ON pta.product_id = fin.product_id
|
||||
AND pta.year = fin.year
|
||||
AND pta.month = fin.month
|
||||
SET
|
||||
pta.inventory_value = COALESCE(fin.inventory_value, 0),
|
||||
pta.gmroi = CASE
|
||||
WHEN COALESCE(fin.inventory_value, 0) > 0 AND fin.days_in_period > 0 THEN
|
||||
(COALESCE(fin.gross_profit, 0) * (365.0 / fin.days_in_period)) / COALESCE(fin.inventory_value, 0)
|
||||
ELSE 0
|
||||
END
|
||||
`);
|
||||
|
||||
return Math.floor(totalProducts * 0.65);
|
||||
} finally {
|
||||
connection.release();
|
||||
}
|
||||
}
|
||||
|
||||
module.exports = calculateTimeAggregates;
|
||||
Reference in New Issue
Block a user