185 lines
6.1 KiB
JavaScript
Executable File
185 lines
6.1 KiB
JavaScript
Executable File
#!/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 <index_name>;');
|
|
console.log('');
|
|
} else {
|
|
console.log(' ✅ Keine großen ungenutzten Indizes gefunden\n');
|
|
}
|
|
}
|
|
|
|
main();
|