118 lines
3.6 KiB
TypeScript
118 lines
3.6 KiB
TypeScript
import { query, pool } from '../db';
|
|
|
|
export const MECHANIC_OPS = {
|
|
// 1. DIAGNOSTICS (The Stethoscope)
|
|
getHealth: async () => {
|
|
const connections = await query(`
|
|
SELECT count(*)::int as active, state
|
|
FROM pg_stat_activity
|
|
GROUP BY state;
|
|
`);
|
|
|
|
const size = await query(`
|
|
SELECT pg_size_pretty(pg_database_size(current_database())) as size;
|
|
`);
|
|
|
|
// Note: pg_statio_user_tables requires stats collection to be enabled (default on)
|
|
const cache = await query(`
|
|
SELECT
|
|
sum(heap_blks_read) as disk_read,
|
|
sum(heap_blks_hit) as mem_hit,
|
|
sum(heap_blks_hit) / NULLIF((sum(heap_blks_hit) + sum(heap_blks_read)), 0)::float as ratio
|
|
FROM pg_statio_user_tables;
|
|
`);
|
|
|
|
return {
|
|
connections: connections.rows,
|
|
size: size.rows[0]?.size || 'Unknown',
|
|
cache: cache.rows[0] || { ratio: 0 }
|
|
};
|
|
},
|
|
|
|
// 2. THE "RED BUTTON" COMMANDS (Fix It)
|
|
maintenance: {
|
|
vacuum: async () => {
|
|
// Cleans up dead rows and optimizes speed
|
|
await query('VACUUM (VERBOSE, ANALYZE);');
|
|
return "Vacuum Complete: DB optimized.";
|
|
},
|
|
reindex: async () => {
|
|
// Fixes corrupted or slow indexes
|
|
await query('REINDEX DATABASE directus;');
|
|
return "Reindex Complete: Indexes rebuilt.";
|
|
},
|
|
kill_locks: async () => {
|
|
// Kills any query running longer than 5 minutes
|
|
const res = await query(`
|
|
SELECT pg_terminate_backend(pid)
|
|
FROM pg_stat_activity
|
|
WHERE state = 'active'
|
|
AND (now() - query_start) > interval '5 minutes';
|
|
`);
|
|
return `Panic Protocol: Terminated ${res.rowCount} stuck processes.`;
|
|
}
|
|
}
|
|
};
|
|
|
|
/**
|
|
* Kill stuck database locks/queries
|
|
* Returns number of processes terminated
|
|
*/
|
|
export async function killLocks(): Promise<number> {
|
|
const result = await query(`
|
|
SELECT pg_terminate_backend(pid)
|
|
FROM pg_stat_activity
|
|
WHERE state = 'active'
|
|
AND query_start < NOW() - INTERVAL '30 seconds'
|
|
AND pid <> pg_backend_pid()
|
|
`);
|
|
|
|
console.log(`🔧 [Mechanic] Killed ${result.rowCount} stuck processes`);
|
|
return result.rowCount || 0;
|
|
}
|
|
|
|
/**
|
|
* Run VACUUM ANALYZE on a table or entire database
|
|
* NOTE: Must be run outside of transaction
|
|
*/
|
|
export async function vacuumAnalyze(tableName?: string): Promise<void> {
|
|
const client = await pool.connect();
|
|
|
|
try {
|
|
const table = tableName || '';
|
|
const sql = table ? `VACUUM ANALYZE ${table}` : 'VACUUM ANALYZE';
|
|
|
|
console.log(`🔧 [Mechanic] Running: ${sql}`);
|
|
await client.query(sql);
|
|
console.log(`✅ [Mechanic] Vacuum complete`);
|
|
|
|
} finally {
|
|
client.release();
|
|
}
|
|
}
|
|
|
|
/**
|
|
* Get table bloat statistics
|
|
*/
|
|
export async function getTableBloat(): Promise<any[]> {
|
|
const result = await query(`
|
|
SELECT
|
|
schemaname,
|
|
tablename,
|
|
pg_size_pretty(pg_total_relation_size(schemaname||'.'||tablename)) as size,
|
|
n_dead_tup as dead_rows,
|
|
n_live_tup as live_rows,
|
|
CASE
|
|
WHEN n_live_tup > 0
|
|
THEN round(100.0 * n_dead_tup / n_live_tup, 2)
|
|
ELSE 0
|
|
END as bloat_pct
|
|
FROM pg_stat_user_tables
|
|
WHERE n_dead_tup > 0
|
|
ORDER BY n_dead_tup DESC
|
|
LIMIT 20
|
|
`);
|
|
|
|
return result.rows;
|
|
}
|