Start migrating and fixing calculate scripts
This commit is contained in:
@@ -64,7 +64,7 @@ const TEMP_TABLES = [
|
||||
async function cleanupTemporaryTables(connection) {
|
||||
try {
|
||||
for (const table of TEMP_TABLES) {
|
||||
await connection.query(`DROP TEMPORARY TABLE IF EXISTS ${table}`);
|
||||
await connection.query(`DROP TABLE IF EXISTS ${table}`);
|
||||
}
|
||||
} catch (error) {
|
||||
logError(error, 'Error cleaning up temporary tables');
|
||||
@@ -127,24 +127,24 @@ async function calculateMetrics() {
|
||||
SET
|
||||
status = 'cancelled',
|
||||
end_time = NOW(),
|
||||
duration_seconds = TIMESTAMPDIFF(SECOND, start_time, NOW()),
|
||||
duration_seconds = EXTRACT(EPOCH FROM (NOW() - start_time))::INTEGER,
|
||||
error_message = 'Previous calculation was not completed properly'
|
||||
WHERE status = 'running'
|
||||
`);
|
||||
|
||||
// Get counts from all relevant tables
|
||||
const [[productCount], [orderCount], [poCount]] = await Promise.all([
|
||||
const [productCountResult, orderCountResult, poCountResult] = await Promise.all([
|
||||
connection.query('SELECT COUNT(*) as total FROM products'),
|
||||
connection.query('SELECT COUNT(*) as total FROM orders'),
|
||||
connection.query('SELECT COUNT(*) as total FROM purchase_orders')
|
||||
]);
|
||||
|
||||
totalProducts = productCount.total;
|
||||
totalOrders = orderCount.total;
|
||||
totalPurchaseOrders = poCount.total;
|
||||
totalProducts = parseInt(productCountResult.rows[0].total);
|
||||
totalOrders = parseInt(orderCountResult.rows[0].total);
|
||||
totalPurchaseOrders = parseInt(poCountResult.rows[0].total);
|
||||
|
||||
// Create history record for this calculation
|
||||
const [historyResult] = await connection.query(`
|
||||
const historyResult = await connection.query(`
|
||||
INSERT INTO calculate_history (
|
||||
start_time,
|
||||
status,
|
||||
@@ -155,19 +155,19 @@ async function calculateMetrics() {
|
||||
) VALUES (
|
||||
NOW(),
|
||||
'running',
|
||||
?,
|
||||
?,
|
||||
?,
|
||||
JSON_OBJECT(
|
||||
'skip_product_metrics', ?,
|
||||
'skip_time_aggregates', ?,
|
||||
'skip_financial_metrics', ?,
|
||||
'skip_vendor_metrics', ?,
|
||||
'skip_category_metrics', ?,
|
||||
'skip_brand_metrics', ?,
|
||||
'skip_sales_forecasts', ?
|
||||
$1,
|
||||
$2,
|
||||
$3,
|
||||
jsonb_build_object(
|
||||
'skip_product_metrics', ($4::int > 0),
|
||||
'skip_time_aggregates', ($5::int > 0),
|
||||
'skip_financial_metrics', ($6::int > 0),
|
||||
'skip_vendor_metrics', ($7::int > 0),
|
||||
'skip_category_metrics', ($8::int > 0),
|
||||
'skip_brand_metrics', ($9::int > 0),
|
||||
'skip_sales_forecasts', ($10::int > 0)
|
||||
)
|
||||
)
|
||||
) RETURNING id
|
||||
`, [
|
||||
totalProducts,
|
||||
totalOrders,
|
||||
@@ -180,8 +180,7 @@ async function calculateMetrics() {
|
||||
SKIP_BRAND_METRICS,
|
||||
SKIP_SALES_FORECASTS
|
||||
]);
|
||||
calculateHistoryId = historyResult.insertId;
|
||||
connection.release();
|
||||
calculateHistoryId = historyResult.rows[0].id;
|
||||
|
||||
// Add debug logging for the progress functions
|
||||
console.log('Debug - Progress functions:', {
|
||||
@@ -199,6 +198,8 @@ async function calculateMetrics() {
|
||||
throw err;
|
||||
}
|
||||
|
||||
// Release the connection before getting a new one
|
||||
connection.release();
|
||||
isCancelled = false;
|
||||
connection = await getConnection();
|
||||
|
||||
@@ -234,10 +235,10 @@ async function calculateMetrics() {
|
||||
await connection.query(`
|
||||
UPDATE calculate_history
|
||||
SET
|
||||
processed_products = ?,
|
||||
processed_orders = ?,
|
||||
processed_purchase_orders = ?
|
||||
WHERE id = ?
|
||||
processed_products = $1,
|
||||
processed_orders = $2,
|
||||
processed_purchase_orders = $3
|
||||
WHERE id = $4
|
||||
`, [safeProducts, safeOrders, safePurchaseOrders, calculateHistoryId]);
|
||||
};
|
||||
|
||||
@@ -383,21 +384,21 @@ async function calculateMetrics() {
|
||||
success: false
|
||||
};
|
||||
|
||||
const [abcConfig] = await connection.query('SELECT a_threshold, b_threshold FROM abc_classification_config WHERE id = 1');
|
||||
const abcThresholds = abcConfig[0] || { a_threshold: 20, b_threshold: 50 };
|
||||
const abcConfigResult = await connection.query('SELECT a_threshold, b_threshold FROM abc_classification_config WHERE id = 1');
|
||||
const abcThresholds = abcConfigResult.rows[0] || { a_threshold: 20, b_threshold: 50 };
|
||||
|
||||
// First, create and populate the rankings table with an index
|
||||
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_revenue_ranks');
|
||||
// First, create and populate the rankings table
|
||||
await connection.query('DROP TABLE IF EXISTS temp_revenue_ranks');
|
||||
await connection.query(`
|
||||
CREATE TEMPORARY TABLE temp_revenue_ranks (
|
||||
pid BIGINT NOT NULL,
|
||||
total_revenue DECIMAL(10,3),
|
||||
rank_num INT,
|
||||
total_count INT,
|
||||
PRIMARY KEY (pid),
|
||||
INDEX (rank_num)
|
||||
) ENGINE=MEMORY
|
||||
PRIMARY KEY (pid)
|
||||
)
|
||||
`);
|
||||
await connection.query('CREATE INDEX ON temp_revenue_ranks (rank_num)');
|
||||
|
||||
outputProgress({
|
||||
status: 'running',
|
||||
@@ -422,25 +423,29 @@ async function calculateMetrics() {
|
||||
success: false
|
||||
};
|
||||
|
||||
// Use window functions instead of user variables
|
||||
await connection.query(`
|
||||
INSERT INTO temp_revenue_ranks
|
||||
WITH ranked AS (
|
||||
SELECT
|
||||
pid,
|
||||
total_revenue,
|
||||
ROW_NUMBER() OVER (ORDER BY total_revenue DESC) as rank_num,
|
||||
COUNT(*) OVER () as total_count
|
||||
FROM product_metrics
|
||||
WHERE total_revenue > 0
|
||||
)
|
||||
SELECT
|
||||
pid,
|
||||
total_revenue,
|
||||
@rank := @rank + 1 as rank_num,
|
||||
@total_count := @rank as total_count
|
||||
FROM (
|
||||
SELECT pid, total_revenue
|
||||
FROM product_metrics
|
||||
WHERE total_revenue > 0
|
||||
ORDER BY total_revenue DESC
|
||||
) ranked,
|
||||
(SELECT @rank := 0) r
|
||||
rank_num,
|
||||
total_count
|
||||
FROM ranked
|
||||
`);
|
||||
|
||||
// Get total count for percentage calculation
|
||||
const [rankingCount] = await connection.query('SELECT MAX(rank_num) as total_count FROM temp_revenue_ranks');
|
||||
const totalCount = rankingCount[0].total_count || 1;
|
||||
const rankingCountResult = await connection.query('SELECT MAX(rank_num) as total_count FROM temp_revenue_ranks');
|
||||
const totalCount = parseInt(rankingCountResult.rows[0].total_count) || 1;
|
||||
const max_rank = totalCount; // Store max_rank for use in classification
|
||||
|
||||
outputProgress({
|
||||
@@ -481,7 +486,7 @@ async function calculateMetrics() {
|
||||
};
|
||||
|
||||
// First get a batch of PIDs that need updating
|
||||
const [pids] = await connection.query(`
|
||||
const pidsResult = await connection.query(`
|
||||
SELECT pm.pid
|
||||
FROM product_metrics pm
|
||||
LEFT JOIN temp_revenue_ranks tr ON pm.pid = tr.pid
|
||||
@@ -489,37 +494,39 @@ async function calculateMetrics() {
|
||||
OR pm.abc_class !=
|
||||
CASE
|
||||
WHEN tr.rank_num IS NULL THEN 'C'
|
||||
WHEN (tr.rank_num / ?) * 100 <= ? THEN 'A'
|
||||
WHEN (tr.rank_num / ?) * 100 <= ? THEN 'B'
|
||||
WHEN (tr.rank_num::float / $1::float) * 100 <= $2 THEN 'A'
|
||||
WHEN (tr.rank_num::float / $1::float) * 100 <= $3 THEN 'B'
|
||||
ELSE 'C'
|
||||
END
|
||||
LIMIT ?
|
||||
LIMIT $4
|
||||
`, [max_rank, abcThresholds.a_threshold,
|
||||
max_rank, abcThresholds.b_threshold,
|
||||
abcThresholds.b_threshold,
|
||||
batchSize]);
|
||||
|
||||
if (pids.length === 0) {
|
||||
if (pidsResult.rows.length === 0) {
|
||||
break;
|
||||
}
|
||||
|
||||
// Then update just those PIDs
|
||||
const [result] = await connection.query(`
|
||||
const pidValues = pidsResult.rows.map(row => row.pid);
|
||||
const result = await connection.query(`
|
||||
UPDATE product_metrics pm
|
||||
LEFT JOIN temp_revenue_ranks tr ON pm.pid = tr.pid
|
||||
SET pm.abc_class =
|
||||
SET abc_class =
|
||||
CASE
|
||||
WHEN tr.rank_num IS NULL THEN 'C'
|
||||
WHEN (tr.rank_num / ?) * 100 <= ? THEN 'A'
|
||||
WHEN (tr.rank_num / ?) * 100 <= ? THEN 'B'
|
||||
WHEN (tr.rank_num::float / $1::float) * 100 <= $2 THEN 'A'
|
||||
WHEN (tr.rank_num::float / $1::float) * 100 <= $3 THEN 'B'
|
||||
ELSE 'C'
|
||||
END,
|
||||
pm.last_calculated_at = NOW()
|
||||
WHERE pm.pid IN (?)
|
||||
last_calculated_at = NOW()
|
||||
FROM temp_revenue_ranks tr
|
||||
WHERE pm.pid = tr.pid AND pm.pid = ANY($4::bigint[])
|
||||
OR (pm.pid = ANY($4::bigint[]) AND tr.pid IS NULL)
|
||||
`, [max_rank, abcThresholds.a_threshold,
|
||||
max_rank, abcThresholds.b_threshold,
|
||||
pids.map(row => row.pid)]);
|
||||
abcThresholds.b_threshold,
|
||||
pidValues]);
|
||||
|
||||
abcProcessedCount += result.affectedRows;
|
||||
abcProcessedCount += result.rowCount;
|
||||
|
||||
// Calculate progress ensuring valid numbers
|
||||
const currentProgress = Math.floor(totalProducts * (0.99 + (abcProcessedCount / (totalCount || 1)) * 0.01));
|
||||
@@ -557,7 +564,7 @@ async function calculateMetrics() {
|
||||
}
|
||||
|
||||
// Clean up
|
||||
await connection.query('DROP TEMPORARY TABLE IF EXISTS temp_revenue_ranks');
|
||||
await connection.query('DROP TABLE IF EXISTS temp_revenue_ranks');
|
||||
|
||||
const endTime = Date.now();
|
||||
const totalElapsedSeconds = Math.round((endTime - startTime) / 1000);
|
||||
@@ -566,7 +573,8 @@ async function calculateMetrics() {
|
||||
await connection.query(`
|
||||
INSERT INTO calculate_status (module_name, last_calculation_timestamp)
|
||||
VALUES ('abc_classification', NOW())
|
||||
ON DUPLICATE KEY UPDATE last_calculation_timestamp = NOW()
|
||||
ON CONFLICT (module_name) DO UPDATE
|
||||
SET last_calculation_timestamp = NOW()
|
||||
`);
|
||||
|
||||
// Final progress update with guaranteed valid numbers
|
||||
@@ -601,12 +609,12 @@ async function calculateMetrics() {
|
||||
UPDATE calculate_history
|
||||
SET
|
||||
end_time = NOW(),
|
||||
duration_seconds = ?,
|
||||
processed_products = ?,
|
||||
processed_orders = ?,
|
||||
processed_purchase_orders = ?,
|
||||
duration_seconds = $1,
|
||||
processed_products = $2,
|
||||
processed_orders = $3,
|
||||
processed_purchase_orders = $4,
|
||||
status = 'completed'
|
||||
WHERE id = ?
|
||||
WHERE id = $5
|
||||
`, [totalElapsedSeconds,
|
||||
finalStats.processedProducts,
|
||||
finalStats.processedOrders,
|
||||
@@ -625,13 +633,13 @@ async function calculateMetrics() {
|
||||
UPDATE calculate_history
|
||||
SET
|
||||
end_time = NOW(),
|
||||
duration_seconds = ?,
|
||||
processed_products = ?,
|
||||
processed_orders = ?,
|
||||
processed_purchase_orders = ?,
|
||||
status = ?,
|
||||
error_message = ?
|
||||
WHERE id = ?
|
||||
duration_seconds = $1,
|
||||
processed_products = $2,
|
||||
processed_orders = $3,
|
||||
processed_purchase_orders = $4,
|
||||
status = $5,
|
||||
error_message = $6
|
||||
WHERE id = $7
|
||||
`, [
|
||||
totalElapsedSeconds,
|
||||
processedProducts || 0, // Ensure we have a valid number
|
||||
|
||||
Reference in New Issue
Block a user