diff --git a/backend/diagnose-db-performance.js b/backend/diagnose-db-performance.js new file mode 100755 index 0000000..5901d33 --- /dev/null +++ b/backend/diagnose-db-performance.js @@ -0,0 +1,473 @@ +#!/usr/bin/env node + +/** + * Umfassendes Diagnose-Script für Datenbank-Performance + * + * Untersucht: + * - Verbindungsstatistiken + * - Langsame Queries + * - Tabellengrößen und Bloat + * - Indizes (fehlende/ungenutzte) + * - Vacuum/Analyze Status + * - Locking/Blocking + * - Query-Statistiken + */ + +import './config/loadEnv.js'; +import { sequelize } from './utils/sequelize.js'; + +async function main() { + try { + console.log('🔍 Datenbank-Performance-Diagnose\n'); + console.log('='.repeat(60) + '\n'); + + // 1. Verbindungsstatistiken + await checkConnections(); + + // 2. Langsame Queries (wenn pg_stat_statements aktiviert ist) + await checkSlowQueries(); + + // 3. Tabellengrößen und Bloat + await checkTableSizes(); + + // 4. Indizes prüfen + await checkIndexes(); + + // 5. Vacuum/Analyze Status + await checkVacuumStatus(); + + // 6. Locking/Blocking + await checkLocks(); + + // 7. Query-Statistiken (wenn pg_stat_statements aktiviert ist) + await checkQueryStats(); + + // 8. Connection Pool Status + await checkConnectionPool(); + + console.log('\n' + '='.repeat(60)); + console.log('✅ Diagnose abgeschlossen\n'); + + await sequelize.close(); + process.exit(0); + + } catch (error) { + console.error('❌ Fehler:', error.message); + console.error(error.stack); + process.exit(1); + } +} + +async function checkConnections() { + console.log('📊 1. Verbindungsstatistiken\n'); + + const [connections] = await sequelize.query(` + SELECT + count(*) as total, + count(*) FILTER (WHERE state = 'active') as active, + count(*) FILTER (WHERE state = 'idle') as idle, + count(*) FILTER (WHERE state = 'idle in transaction') as idle_in_transaction, + count(*) FILTER (WHERE wait_event_type IS NOT NULL) as waiting + FROM pg_stat_activity + WHERE datname = current_database(); + `); + + const conn = connections[0]; + console.log(` Gesamt: ${conn.total}`); + console.log(` Aktiv: ${conn.active}`); + console.log(` Idle: ${conn.idle}`); + console.log(` Idle in Transaction: ${conn.idle_in_transaction}`); + console.log(` Wartend: ${conn.waiting}\n`); + + const [maxConn] = await sequelize.query(` + SELECT setting::int as max_connections + FROM pg_settings + WHERE name = 'max_connections'; + `); + + const usagePercent = (conn.total / maxConn[0].max_connections) * 100; + console.log(` Max Connections: ${maxConn[0].max_connections}`); + console.log(` Auslastung: ${usagePercent.toFixed(1)}%\n`); + + if (usagePercent > 80) { + console.log(' ⚠️ WARNUNG: Hohe Verbindungsauslastung!\n'); + } + + // Zeige lange laufende Queries + const [longRunning] = await sequelize.query(` + SELECT + pid, + usename, + application_name, + state, + now() - query_start as duration, + wait_event_type, + wait_event, + left(query, 100) as query_preview + FROM pg_stat_activity + WHERE datname = current_database() + AND state != 'idle' + AND now() - query_start > interval '5 seconds' + ORDER BY query_start ASC + LIMIT 10; + `); + + if (longRunning.length > 0) { + console.log(' ⚠️ Lange laufende Queries (> 5 Sekunden):'); + longRunning.forEach(q => { + const duration = Math.round(q.duration.total_seconds); + console.log(` PID ${q.pid}: ${duration}s - ${q.query_preview}...`); + }); + console.log(''); + } +} + +async function checkSlowQueries() { + console.log('🐌 2. Langsame Queries (pg_stat_statements)\n'); + + try { + // Prüfe ob pg_stat_statements aktiviert ist + const [extension] = await sequelize.query(` + SELECT EXISTS( + SELECT 1 FROM pg_extension WHERE extname = 'pg_stat_statements' + ) as exists; + `); + + if (!extension[0].exists) { + console.log(' ℹ️ pg_stat_statements ist nicht aktiviert.'); + console.log(' 💡 Aktivieren mit: CREATE EXTENSION IF NOT EXISTS pg_stat_statements;\n'); + return; + } + + const [slowQueries] = await sequelize.query(` + SELECT + left(query, 100) as query_preview, + calls, + total_exec_time, + mean_exec_time, + max_exec_time, + (total_exec_time / sum(total_exec_time) OVER ()) * 100 as percent_total + FROM pg_stat_statements + WHERE mean_exec_time > 100 -- Queries mit > 100ms Durchschnitt + ORDER BY total_exec_time DESC + LIMIT 10; + `); + + if (slowQueries.length > 0) { + console.log(' Top 10 langsamste Queries (nach Gesamtzeit):'); + slowQueries.forEach((q, i) => { + console.log(` ${i + 1}. ${q.query_preview}...`); + console.log(` Aufrufe: ${q.calls}, Durchschnitt: ${q.mean_exec_time.toFixed(2)}ms, Max: ${q.max_exec_time.toFixed(2)}ms`); + console.log(` Gesamtzeit: ${q.total_exec_time.toFixed(2)}ms (${q.percent_total.toFixed(1)}%)\n`); + }); + } else { + console.log(' ✅ Keine sehr langsamen Queries gefunden (> 100ms Durchschnitt)\n'); + } + } catch (error) { + console.log(` ⚠️ Fehler beim Abrufen der Query-Statistiken: ${error.message}\n`); + } +} + +async function checkTableSizes() { + console.log('📦 3. Tabellengrößen und Bloat\n'); + + const [tableSizes] = await sequelize.query(` + SELECT + schemaname || '.' || tablename as full_table_name, + pg_size_pretty(pg_total_relation_size(schemaname||'.'||tablename)) as total_size, + pg_size_pretty(pg_relation_size(schemaname||'.'||tablename)) as table_size, + pg_size_pretty(pg_total_relation_size(schemaname||'.'||tablename) - pg_relation_size(schemaname||'.'||tablename)) as indexes_size, + n_live_tup as row_count, + n_dead_tup as dead_rows, + CASE + WHEN n_live_tup > 0 THEN round((n_dead_tup::numeric / n_live_tup::numeric) * 100, 2) + ELSE 0 + END as dead_row_percent, + last_vacuum, + last_autovacuum, + last_analyze, + last_autoanalyze + FROM pg_stat_user_tables + WHERE schemaname IN ('falukant_data', 'falukant_type', 'community', 'logs') + ORDER BY pg_total_relation_size(schemaname||'.'||tablename) DESC + LIMIT 20; + `); + + if (tableSizes.length > 0) { + console.log(' Top 20 größte Tabellen:'); + tableSizes.forEach((t, i) => { + console.log(` ${i + 1}. ${t.full_table_name}`); + console.log(` Größe: ${t.total_size} (Tabelle: ${t.table_size}, Indizes: ${t.indexes_size})`); + console.log(` Zeilen: ${parseInt(t.row_count).toLocaleString()}, Tote Zeilen: ${parseInt(t.dead_rows).toLocaleString()} (${t.dead_row_percent}%)`); + + if (parseFloat(t.dead_row_percent) > 20) { + console.log(` ⚠️ Hoher Bloat-Anteil! Vacuum empfohlen.`); + } + + if (t.last_vacuum || t.last_autovacuum) { + const lastVacuum = t.last_vacuum || t.last_autovacuum; + const daysSinceVacuum = Math.floor((new Date() - new Date(lastVacuum)) / (1000 * 60 * 60 * 24)); + if (daysSinceVacuum > 7) { + console.log(` ⚠️ Letztes Vacuum: ${daysSinceVacuum} Tage her`); + } + } + console.log(''); + }); + } +} + +async function checkIndexes() { + console.log('🔍 4. Indizes-Analyse\n'); + + // Fehlende Indizes (basierend auf pg_stat_user_tables) + const [missingIndexes] = await sequelize.query(` + SELECT + schemaname || '.' || tablename as table_name, + seq_scan, + seq_tup_read, + idx_scan, + seq_tup_read / NULLIF(seq_scan, 0) as avg_seq_read + FROM pg_stat_user_tables + WHERE schemaname IN ('falukant_data', 'falukant_type', 'community', 'logs') + AND seq_scan > 1000 + AND seq_tup_read / NULLIF(seq_scan, 0) > 1000 + ORDER BY seq_tup_read DESC + LIMIT 10; + `); + + if (missingIndexes.length > 0) { + console.log(' ⚠️ Tabellen mit vielen Sequential Scans (möglicherweise fehlende Indizes):'); + missingIndexes.forEach(t => { + console.log(` ${t.table_name}: ${t.seq_scan} seq scans, ${parseInt(t.seq_tup_read).toLocaleString()} Zeilen gelesen`); + }); + console.log(''); + } + + // Ungenutzte Indizes + const [unusedIndexes] = await sequelize.query(` + SELECT + schemaname || '.' || indexrelname as index_name, + schemaname || '.' || tablename as table_name, + pg_size_pretty(pg_relation_size(indexrelid)) as index_size, + idx_scan as scans + 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 (unusedIndexes.length > 0) { + console.log(' ⚠️ Ungenutzte Indizes (> 1MB, nie verwendet):'); + unusedIndexes.forEach(idx => { + console.log(` ${idx.index_name} auf ${idx.table_name}: ${idx.index_size} (0 Scans)`); + }); + console.log(''); + } + + // Index Bloat + const [indexBloat] = await sequelize.query(` + SELECT + schemaname || '.' || indexrelname as index_name, + schemaname || '.' || tablename as table_name, + pg_size_pretty(pg_relation_size(indexrelid)) as index_size, + idx_scan as scans, + idx_tup_read as tuples_read, + idx_tup_fetch as tuples_fetched + FROM pg_stat_user_indexes + WHERE schemaname IN ('falukant_data', 'falukant_type', 'community', 'logs') + AND pg_relation_size(indexrelid) > 10 * 1024 * 1024 -- Größer als 10MB + ORDER BY pg_relation_size(indexrelid) DESC + LIMIT 10; + `); + + if (indexBloat.length > 0) { + console.log(' Top 10 größte Indizes:'); + indexBloat.forEach(idx => { + console.log(` ${idx.index_name} auf ${idx.table_name}: ${idx.index_size} (${idx.scans} Scans)`); + }); + console.log(''); + } +} + +async function checkVacuumStatus() { + console.log('🧹 5. Vacuum/Analyze Status\n'); + + const [vacuumStats] = await sequelize.query(` + SELECT + schemaname || '.' || tablename as table_name, + last_vacuum, + last_autovacuum, + last_analyze, + last_autoanalyze, + 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 + FROM pg_stat_user_tables + WHERE schemaname IN ('falukant_data', 'falukant_type', 'community', 'logs') + AND ( + (last_vacuum IS NULL AND last_autovacuum IS NULL) + OR (last_vacuum < now() - interval '7 days' AND last_autovacuum < now() - interval '7 days') + OR n_dead_tup > 10000 + ) + ORDER BY n_dead_tup DESC + LIMIT 10; + `); + + if (vacuumStats.length > 0) { + console.log(' ⚠️ Tabellen, die Vacuum benötigen könnten:'); + vacuumStats.forEach(t => { + const lastVacuum = t.last_vacuum || t.last_autovacuum || 'Nie'; + const daysSince = lastVacuum !== 'Nie' + ? Math.floor((new Date() - new Date(lastVacuum)) / (1000 * 60 * 60 * 24)) + : '∞'; + console.log(` ${t.table_name}:`); + console.log(` Tote Zeilen: ${parseInt(t.n_dead_tup).toLocaleString()} (${t.dead_percent}%)`); + console.log(` Letztes Vacuum: ${lastVacuum} (${daysSince} Tage)`); + }); + console.log(''); + } else { + console.log(' ✅ Alle Tabellen sind aktuell gevacuumt\n'); + } +} + +async function checkLocks() { + console.log('🔒 6. Locking/Blocking\n'); + + const [locks] = await sequelize.query(` + SELECT + blocked_locks.pid AS blocked_pid, + blocked_activity.usename AS blocked_user, + blocking_locks.pid AS blocking_pid, + blocking_activity.usename AS blocking_user, + blocked_activity.query AS blocked_statement, + blocking_activity.query AS blocking_statement, + blocked_activity.application_name AS blocked_app, + blocking_activity.application_name AS blocking_app + FROM pg_catalog.pg_locks blocked_locks + JOIN pg_catalog.pg_stat_activity blocked_activity ON blocked_activity.pid = blocked_locks.pid + JOIN pg_catalog.pg_locks blocking_locks + ON blocking_locks.locktype = blocked_locks.locktype + AND blocking_locks.database IS NOT DISTINCT FROM blocked_locks.database + AND blocking_locks.relation IS NOT DISTINCT FROM blocked_locks.relation + AND blocking_locks.page IS NOT DISTINCT FROM blocked_locks.page + AND blocking_locks.tuple IS NOT DISTINCT FROM blocked_locks.tuple + AND blocking_locks.virtualxid IS NOT DISTINCT FROM blocked_locks.virtualxid + AND blocking_locks.transactionid IS NOT DISTINCT FROM blocked_locks.transactionid + AND blocking_locks.classid IS NOT DISTINCT FROM blocked_locks.classid + AND blocking_locks.objid IS NOT DISTINCT FROM blocked_locks.objid + AND blocking_locks.objsubid IS NOT DISTINCT FROM blocked_locks.objsubid + AND blocking_locks.pid != blocked_locks.pid + JOIN pg_catalog.pg_stat_activity blocking_activity ON blocking_activity.pid = blocking_locks.pid + WHERE NOT blocked_locks.granted; + `); + + if (locks.length > 0) { + console.log(' ⚠️ Blockierte Queries gefunden:'); + locks.forEach(lock => { + console.log(` Blockiert: PID ${lock.blocked_pid} (${lock.blocked_user})`); + console.log(` Blockiert von: PID ${lock.blocking_pid} (${lock.blocking_user})`); + console.log(` Blockierte Query: ${lock.blocked_statement.substring(0, 100)}...`); + console.log(` Blockierende Query: ${lock.blocking_statement.substring(0, 100)}...\n`); + }); + } else { + console.log(' ✅ Keine blockierten Queries gefunden\n'); + } + + // Zeige alle aktiven Locks + const [allLocks] = await sequelize.query(` + SELECT + locktype, + relation::regclass as relation, + mode, + granted, + pid + FROM pg_locks + WHERE relation IS NOT NULL + AND NOT granted + LIMIT 10; + `); + + if (allLocks.length > 0) { + console.log(' ⚠️ Wartende Locks:'); + allLocks.forEach(lock => { + console.log(` ${lock.locktype} auf ${lock.relation}: ${lock.mode} (PID ${lock.pid})`); + }); + console.log(''); + } +} + +async function checkQueryStats() { + console.log('📈 7. Query-Statistiken\n'); + + try { + const [extension] = await sequelize.query(` + SELECT EXISTS( + SELECT 1 FROM pg_extension WHERE extname = 'pg_stat_statements' + ) as exists; + `); + + if (!extension[0].exists) { + console.log(' ℹ️ pg_stat_statements ist nicht aktiviert.\n'); + return; + } + + const [topQueries] = await sequelize.query(` + SELECT + left(query, 80) as query_preview, + calls, + total_exec_time, + mean_exec_time, + (100 * total_exec_time / sum(total_exec_time) OVER ()) as percent_total + FROM pg_stat_statements + WHERE query NOT LIKE '%pg_stat_statements%' + ORDER BY calls DESC + LIMIT 5; + `); + + if (topQueries.length > 0) { + console.log(' Top 5 häufigste Queries:'); + topQueries.forEach((q, i) => { + console.log(` ${i + 1}. ${q.query_preview}...`); + console.log(` Aufrufe: ${parseInt(q.calls).toLocaleString()}, Durchschnitt: ${q.mean_exec_time.toFixed(2)}ms`); + }); + console.log(''); + } + } catch (error) { + console.log(` ⚠️ Fehler: ${error.message}\n`); + } +} + +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; + + console.log(` Pool-Status:`); + console.log(` Größe: ${poolSize}`); + console.log(` Verwendet: ${poolUsed}`); + console.log(` Wartend: ${poolPending}\n`); + } catch (error) { + // Pool-Status möglicherweise nicht verfügbar + console.log(` ℹ️ Detaillierter Pool-Status nicht verfügbar\n`); + } +} + +main();