diff --git a/backend/analyze-indexes.js b/backend/analyze-indexes.js new file mode 100755 index 0000000..30049a3 --- /dev/null +++ b/backend/analyze-indexes.js @@ -0,0 +1,184 @@ +#!/usr/bin/env node + +/** + * Script zur Analyse und Empfehlung von Indizes + * + * Analysiert: + * - Tabellen mit vielen Sequential Scans + * - Fehlende Composite Indizes für häufige JOINs + * - Ungenutzte Indizes + */ + +import './config/loadEnv.js'; +import { sequelize } from './utils/sequelize.js'; + +async function main() { + try { + console.log('🔍 Index-Analyse und Empfehlungen\n'); + console.log('='.repeat(60) + '\n'); + + // 1. Tabellen mit vielen Sequential Scans + await analyzeSequentialScans(); + + // 2. Prüfe häufige JOIN-Patterns + await analyzeJoinPatterns(); + + // 3. Ungenutzte Indizes + await analyzeUnusedIndexes(); + + console.log('='.repeat(60)); + console.log('✅ Analyse abgeschlossen\n'); + + await sequelize.close(); + process.exit(0); + + } catch (error) { + console.error('❌ Fehler:', error.message); + console.error(error.stack); + process.exit(1); + } +} + +async function analyzeSequentialScans() { + console.log('📊 1. Tabellen mit vielen Sequential Scans\n'); + + const [tables] = await sequelize.query(` + SELECT + schemaname || '.' || relname as table_name, + seq_scan, + seq_tup_read, + idx_scan, + seq_tup_read / NULLIF(seq_scan, 0) as avg_rows_per_scan, + CASE + WHEN seq_scan + idx_scan > 0 + THEN round((seq_scan::numeric / (seq_scan + idx_scan)) * 100, 2) + ELSE 0 + END as seq_scan_percent + FROM pg_stat_user_tables + WHERE schemaname IN ('falukant_data', 'falukant_type', 'community', 'logs') + AND seq_scan > 1000 + ORDER BY seq_tup_read DESC + LIMIT 10; + `); + + if (tables.length > 0) { + console.log(' ⚠️ Tabellen mit vielen Sequential Scans:'); + tables.forEach(t => { + console.log(`\n ${t.table_name}:`); + console.log(` Sequential Scans: ${parseInt(t.seq_scan).toLocaleString()}`); + console.log(` Zeilen gelesen: ${parseInt(t.seq_tup_read).toLocaleString()}`); + console.log(` Index Scans: ${parseInt(t.idx_scan).toLocaleString()}`); + console.log(` Seq Scan Anteil: ${t.seq_scan_percent}%`); + console.log(` Ø Zeilen pro Scan: ${parseInt(t.avg_rows_per_scan).toLocaleString()}`); + + if (t.seq_scan_percent > 50) { + console.log(` ⚠️ KRITISCH: Mehr als 50% Sequential Scans!`); + } + }); + console.log(''); + } +} + +async function analyzeJoinPatterns() { + console.log('🔗 2. Analyse häufiger JOIN-Patterns\n'); + + // Prüfe welche Indizes auf knowledge existieren + const [knowledgeIndexes] = await sequelize.query(` + SELECT + indexname, + indexdef + FROM pg_indexes + WHERE schemaname = 'falukant_data' + AND tablename = 'knowledge' + ORDER BY indexname; + `); + + console.log(' Indizes auf falukant_data.knowledge:'); + if (knowledgeIndexes.length > 0) { + knowledgeIndexes.forEach(idx => { + console.log(` - ${idx.indexname}: ${idx.indexdef}`); + }); + } else { + console.log(' Keine Indizes gefunden'); + } + console.log(''); + + // Empfehlung: Composite Index auf (character_id, product_id) + const [knowledgeUsage] = await sequelize.query(` + SELECT + idx_scan, + idx_tup_read, + idx_tup_fetch + FROM pg_stat_user_indexes + WHERE schemaname = 'falukant_data' + AND relname = 'knowledge' + AND indexrelname = 'idx_knowledge_character_id'; + `); + + if (knowledgeUsage.length > 0) { + const usage = knowledgeUsage[0]; + console.log(' Aktuelle Nutzung von idx_knowledge_character_id:'); + console.log(` Scans: ${parseInt(usage.idx_scan).toLocaleString()}`); + console.log(` Zeilen gelesen: ${parseInt(usage.idx_tup_read).toLocaleString()}`); + console.log(''); + + console.log(' 💡 Empfehlung:'); + console.log(' CREATE INDEX IF NOT EXISTS idx_knowledge_character_product'); + console.log(' ON falukant_data.knowledge(character_id, product_id);'); + console.log(' → Wird häufig für JOINs mit character_id UND product_id verwendet\n'); + } + + // Prüfe character Indizes + const [characterIndexes] = await sequelize.query(` + SELECT + indexname, + indexdef + FROM pg_indexes + WHERE schemaname = 'falukant_data' + AND tablename = 'character' + ORDER BY indexname; + `); + + console.log(' Indizes auf falukant_data.character:'); + if (characterIndexes.length > 0) { + characterIndexes.forEach(idx => { + console.log(` - ${idx.indexname}: ${idx.indexdef}`); + }); + } + console.log(''); +} + +async function analyzeUnusedIndexes() { + console.log('🗑️ 3. Ungenutzte Indizes\n'); + + const [unused] = await sequelize.query(` + SELECT + schemaname || '.' || indexrelname as index_name, + schemaname || '.' || relname as table_name, + pg_size_pretty(pg_relation_size(indexrelid)) as index_size, + idx_scan as scans, + pg_relation_size(indexrelid) as size_bytes + FROM pg_stat_user_indexes + WHERE schemaname IN ('falukant_data', 'falukant_type', 'community', 'logs') + AND idx_scan = 0 + AND pg_relation_size(indexrelid) > 1024 * 1024 -- Größer als 1MB + ORDER BY pg_relation_size(indexrelid) DESC + LIMIT 10; + `); + + if (unused.length > 0) { + console.log(' ⚠️ Ungenutzte Indizes (> 1MB):'); + unused.forEach(idx => { + console.log(` ${idx.index_name} auf ${idx.table_name}`); + console.log(` Größe: ${idx.index_size}, Scans: ${idx.scans}`); + }); + console.log(''); + console.log(' 💡 Überlege, ob diese Indizes gelöscht werden können:'); + console.log(' DROP INDEX IF EXISTS ;'); + console.log(''); + } else { + console.log(' ✅ Keine großen ungenutzten Indizes gefunden\n'); + } +} + +main(); diff --git a/backend/diagnose-db-performance.js b/backend/diagnose-db-performance.js index e29d257..100779c 100755 --- a/backend/diagnose-db-performance.js +++ b/backend/diagnose-db-performance.js @@ -445,28 +445,34 @@ async function checkQueryStats() { async function checkConnectionPool() { console.log('🏊 8. Connection Pool Status\n'); - const pool = sequelize.connectionManager.pool; - - console.log(` Pool-Konfiguration:`); - console.log(` Max: ${pool.max}`); - console.log(` Min: ${pool.min}`); - console.log(` Acquire Timeout: ${pool.acquire}ms`); - console.log(` Idle Timeout: ${pool.idle}ms`); - console.log(` Evict Interval: ${pool.evict}ms\n`); - - // Versuche Pool-Status zu bekommen (falls verfügbar) try { - const poolSize = pool.size || 0; - const poolUsed = pool.used || 0; - const poolPending = pool.pending || 0; + // Hole Pool-Konfiguration aus Sequelize Config + const config = sequelize.config; + const poolConfig = config.pool || {}; - console.log(` Pool-Status:`); - console.log(` Größe: ${poolSize}`); - console.log(` Verwendet: ${poolUsed}`); - console.log(` Wartend: ${poolPending}\n`); + console.log(` Pool-Konfiguration:`); + console.log(` Max: ${poolConfig.max || 'N/A'}`); + console.log(` Min: ${poolConfig.min || 'N/A'}`); + console.log(` Acquire Timeout: ${poolConfig.acquire || 'N/A'}ms`); + console.log(` Idle Timeout: ${poolConfig.idle || 'N/A'}ms`); + console.log(` Evict Interval: ${poolConfig.evict || 'N/A'}ms\n`); + + // Versuche Pool-Status zu bekommen + const pool = sequelize.connectionManager.pool; + if (pool) { + const poolSize = pool.size || 0; + const poolUsed = pool.used || 0; + const poolPending = pool.pending || 0; + + console.log(` Pool-Status:`); + console.log(` Größe: ${poolSize}`); + console.log(` Verwendet: ${poolUsed}`); + console.log(` Wartend: ${poolPending}\n`); + } else { + console.log(` ℹ️ Pool-Objekt nicht verfügbar\n`); + } } catch (error) { - // Pool-Status möglicherweise nicht verfügbar - console.log(` ℹ️ Detaillierter Pool-Status nicht verfügbar\n`); + console.log(` ⚠️ Fehler beim Abrufen der Pool-Informationen: ${error.message}\n`); } } diff --git a/backend/vacuum-database.js b/backend/vacuum-database.js new file mode 100755 index 0000000..6cd444e --- /dev/null +++ b/backend/vacuum-database.js @@ -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();