Refactor connection pool diagnostics in diagnose-db-performance.js: Update pool configuration retrieval to use Sequelize config, improve error handling, and enhance console output for better clarity on pool status. This change ensures more accurate diagnostics and user feedback regarding database connection pooling.
This commit is contained in:
113
backend/vacuum-database.js
Executable file
113
backend/vacuum-database.js
Executable file
@@ -0,0 +1,113 @@
|
||||
#!/usr/bin/env node
|
||||
|
||||
/**
|
||||
* Script zum Ausführen von VACUUM auf Tabellen mit hohem Bloat
|
||||
*
|
||||
* Führt VACUUM ANALYZE auf Tabellen aus, die:
|
||||
* - Hohen Bloat-Anteil haben (> 20% tote Zeilen)
|
||||
* - Seit mehr als 7 Tagen nicht gevacuumt wurden
|
||||
* - Viele tote Zeilen haben (> 1000)
|
||||
*/
|
||||
|
||||
import './config/loadEnv.js';
|
||||
import { sequelize } from './utils/sequelize.js';
|
||||
|
||||
async function main() {
|
||||
try {
|
||||
console.log('🧹 Datenbank-Vacuum\n');
|
||||
console.log('='.repeat(60) + '\n');
|
||||
|
||||
// Finde Tabellen, die Vacuum benötigen
|
||||
const [tablesToVacuum] = await sequelize.query(`
|
||||
SELECT
|
||||
schemaname || '.' || relname as table_name,
|
||||
n_dead_tup,
|
||||
n_live_tup,
|
||||
CASE
|
||||
WHEN n_live_tup > 0 THEN round((n_dead_tup::numeric / n_live_tup::numeric) * 100, 2)
|
||||
ELSE 0
|
||||
END as dead_percent,
|
||||
last_vacuum,
|
||||
last_autovacuum,
|
||||
pg_size_pretty(pg_total_relation_size(schemaname||'.'||relname)) as table_size
|
||||
FROM pg_stat_user_tables
|
||||
WHERE schemaname IN ('falukant_data', 'falukant_type', 'community', 'logs')
|
||||
AND (
|
||||
(n_dead_tup > 1000 AND (n_live_tup = 0 OR (n_dead_tup::numeric / NULLIF(n_live_tup, 0)) > 0.2))
|
||||
OR (last_vacuum IS NULL AND last_autovacuum IS NULL AND n_dead_tup > 0)
|
||||
OR (
|
||||
(last_vacuum < now() - interval '7 days' OR last_vacuum IS NULL)
|
||||
AND (last_autovacuum < now() - interval '7 days' OR last_autovacuum IS NULL)
|
||||
AND n_dead_tup > 100
|
||||
)
|
||||
)
|
||||
ORDER BY n_dead_tup DESC;
|
||||
`);
|
||||
|
||||
if (tablesToVacuum.length === 0) {
|
||||
console.log('✅ Keine Tabellen benötigen Vacuum.\n');
|
||||
await sequelize.close();
|
||||
process.exit(0);
|
||||
}
|
||||
|
||||
console.log(`📋 Gefunden: ${tablesToVacuum.length} Tabellen benötigen Vacuum\n`);
|
||||
|
||||
// Zeige Tabellen
|
||||
console.log('Tabellen, die gevacuumt werden:');
|
||||
tablesToVacuum.forEach((t, i) => {
|
||||
console.log(` ${i + 1}. ${t.table_name}`);
|
||||
console.log(` Größe: ${t.table_size}, Tote Zeilen: ${parseInt(t.n_dead_tup).toLocaleString()} (${t.dead_percent}%)`);
|
||||
});
|
||||
console.log('');
|
||||
|
||||
// Frage Bestätigung
|
||||
const readline = require('readline');
|
||||
const rl = readline.createInterface({
|
||||
input: process.stdin,
|
||||
output: process.stdout
|
||||
});
|
||||
|
||||
const answer = await new Promise((resolve) => {
|
||||
rl.question('Möchtest du VACUUM ANALYZE auf diesen Tabellen ausführen? (j/n): ', resolve);
|
||||
});
|
||||
rl.close();
|
||||
|
||||
if (answer.toLowerCase() !== 'j' && answer.toLowerCase() !== 'y' && answer.toLowerCase() !== 'ja' && answer.toLowerCase() !== 'yes') {
|
||||
console.log('❌ Abgebrochen.\n');
|
||||
await sequelize.close();
|
||||
process.exit(0);
|
||||
}
|
||||
|
||||
console.log('\n🧹 Starte Vacuum...\n');
|
||||
|
||||
// Führe VACUUM ANALYZE aus
|
||||
for (let i = 0; i < tablesToVacuum.length; i++) {
|
||||
const table = tablesToVacuum[i];
|
||||
const startTime = Date.now();
|
||||
|
||||
try {
|
||||
console.log(`[${i + 1}/${tablesToVacuum.length}] Vacuuming ${table.table_name}...`);
|
||||
|
||||
await sequelize.query(`VACUUM ANALYZE ${table.table_name};`);
|
||||
|
||||
const duration = ((Date.now() - startTime) / 1000).toFixed(2);
|
||||
console.log(` ✅ Fertig in ${duration}s\n`);
|
||||
} catch (error) {
|
||||
console.error(` ❌ Fehler: ${error.message}\n`);
|
||||
}
|
||||
}
|
||||
|
||||
console.log('='.repeat(60));
|
||||
console.log('✅ Vacuum abgeschlossen\n');
|
||||
|
||||
await sequelize.close();
|
||||
process.exit(0);
|
||||
|
||||
} catch (error) {
|
||||
console.error('❌ Fehler:', error.message);
|
||||
console.error(error.stack);
|
||||
process.exit(1);
|
||||
}
|
||||
}
|
||||
|
||||
main();
|
||||
Reference in New Issue
Block a user