236 lines
6.7 KiB
TypeScript
236 lines
6.7 KiB
TypeScript
// Connection Pool Monitoring & Management
|
|
// Prevents connection leaks and monitors database pressure
|
|
// Part of the "Reaper" Maintenance System
|
|
|
|
import { pool } from '@/lib/db';
|
|
|
|
export interface PoolStats {
|
|
totalCount: number; // Total connections in pool
|
|
idleCount: number; // Idle connections
|
|
waitingCount: number; // Clients waiting for connection
|
|
maxConnections: number; // Pool max setting
|
|
utilizationPercent: number;
|
|
status: 'healthy' | 'warning' | 'critical';
|
|
message: string;
|
|
}
|
|
|
|
/**
|
|
* Get current connection pool statistics
|
|
*/
|
|
export function getPoolStats(): PoolStats {
|
|
const totalCount = pool.totalCount;
|
|
const idleCount = pool.idleCount;
|
|
const waitingCount = pool.waitingCount;
|
|
const maxConnections = pool.options.max || 20;
|
|
|
|
const utilizationPercent = (totalCount / maxConnections) * 100;
|
|
|
|
let status: 'healthy' | 'warning' | 'critical' = 'healthy';
|
|
let message = 'Pool operating normally';
|
|
|
|
if (utilizationPercent > 90) {
|
|
status = 'critical';
|
|
message = `🚨 CRITICAL: Pool at ${utilizationPercent.toFixed(1)}% capacity. Risk of connection exhaustion!`;
|
|
} else if (utilizationPercent > 70) {
|
|
status = 'warning';
|
|
message = `⚠️ WARNING: Pool at ${utilizationPercent.toFixed(1)}% capacity. Monitor closely.`;
|
|
}
|
|
|
|
if (waitingCount > 0) {
|
|
status = waitingCount > 5 ? 'critical' : 'warning';
|
|
message = `${waitingCount} clients waiting for connection. Consider increasing pool size.`;
|
|
}
|
|
|
|
return {
|
|
totalCount,
|
|
idleCount,
|
|
waitingCount,
|
|
maxConnections,
|
|
utilizationPercent: Math.round(utilizationPercent),
|
|
status,
|
|
message
|
|
};
|
|
}
|
|
|
|
/**
|
|
* Force close idle connections (use sparingly)
|
|
*/
|
|
export async function pruneIdleConnections(): Promise<number> {
|
|
const stats = getPoolStats();
|
|
const idleCount = stats.idleCount;
|
|
|
|
// This will close idle connections on next pool.connect() call
|
|
// Not recommended unless experiencing issues
|
|
console.warn('[Pool] Pruning idle connections...');
|
|
|
|
return idleCount;
|
|
}
|
|
|
|
/**
|
|
* Gracefully drain pool (for shutdown)
|
|
*/
|
|
export async function drainPool(timeoutMs: number = 5000): Promise<void> {
|
|
console.log('[Pool] Draining connection pool...');
|
|
|
|
const drainPromise = pool.end();
|
|
const timeoutPromise = new Promise((_, reject) =>
|
|
setTimeout(() => reject(new Error('Pool drain timeout')), timeoutMs)
|
|
);
|
|
|
|
try {
|
|
await Promise.race([drainPromise, timeoutPromise]);
|
|
console.log('[Pool] Connection pool drained successfully');
|
|
} catch (error) {
|
|
console.error('[Pool] Error draining pool:', error);
|
|
throw error;
|
|
}
|
|
}
|
|
|
|
/**
|
|
* Monitor pool health and log warnings
|
|
* Call this periodically from a background timer
|
|
*/
|
|
export function monitorPoolHealth(): PoolStats {
|
|
const stats = getPoolStats();
|
|
|
|
if (stats.status === 'critical') {
|
|
console.error('[Pool Health]', stats.message, stats);
|
|
} else if (stats.status === 'warning') {
|
|
console.warn('[Pool Health]', stats.message, stats);
|
|
}
|
|
|
|
return stats;
|
|
}
|
|
|
|
/**
|
|
* Safe query wrapper with automatic connection release
|
|
* Use this instead of pool.query() directly to prevent leaks
|
|
*/
|
|
export async function safeQuery<T = any>(
|
|
sql: string,
|
|
params?: any[]
|
|
): Promise<{ rows: T[]; rowCount: number | null }> {
|
|
const client = await pool.connect();
|
|
|
|
try {
|
|
const result = await client.query<T>(sql, params);
|
|
return {
|
|
rows: result.rows,
|
|
rowCount: result.rowCount
|
|
};
|
|
} catch (error) {
|
|
console.error('[DB Error]', error);
|
|
throw error;
|
|
} finally {
|
|
// CRITICAL: Always release connection back to pool
|
|
client.release();
|
|
}
|
|
}
|
|
|
|
/**
|
|
* Execute transaction with automatic rollback on error
|
|
*/
|
|
export async function executeTransaction<T>(
|
|
callback: (client: any) => Promise<T>
|
|
): Promise<T> {
|
|
const client = await pool.connect();
|
|
|
|
try {
|
|
await client.query('BEGIN');
|
|
const result = await callback(client);
|
|
await client.query('COMMIT');
|
|
return result;
|
|
} catch (error) {
|
|
await client.query('ROLLBACK');
|
|
console.error('[Transaction Error]', error);
|
|
throw error;
|
|
} finally {
|
|
client.release();
|
|
}
|
|
}
|
|
|
|
/**
|
|
* Get database size and table stats
|
|
* Useful for monitoring vacuum requirements
|
|
*/
|
|
export async function getDatabaseStats(): Promise<{
|
|
databaseSize: string;
|
|
tableStats: Array<{ table: string; rowCount: number; tableSize: string }>;
|
|
}> {
|
|
// Get database size
|
|
const { rows: sizeRows } = await pool.query<{ size: string }>(
|
|
"SELECT pg_size_pretty(pg_database_size(current_database())) as size"
|
|
);
|
|
|
|
// Get table stats
|
|
const { rows: tableRows } = await pool.query<{
|
|
table: string;
|
|
row_count: string;
|
|
table_size: string;
|
|
}>(
|
|
`SELECT
|
|
schemaname || '.' || tablename as table,
|
|
n_live_tup as row_count,
|
|
pg_size_pretty(pg_total_relation_size(schemaname || '.' || tablename)) as table_size
|
|
FROM pg_stat_user_tables
|
|
ORDER BY n_live_tup DESC
|
|
LIMIT 20`
|
|
);
|
|
|
|
return {
|
|
databaseSize: sizeRows[0]?.size || 'Unknown',
|
|
tableStats: tableRows.map(row => ({
|
|
table: row.table,
|
|
rowCount: parseInt(row.row_count) || 0,
|
|
tableSize: row.table_size
|
|
}))
|
|
};
|
|
}
|
|
|
|
/**
|
|
* Check if VACUUM is needed
|
|
* Returns tables that need vacuuming based on dead tuple count
|
|
*/
|
|
export async function getVacuumCandidates(): Promise<Array<{
|
|
table: string;
|
|
deadTuples: number;
|
|
liveTuples: number;
|
|
deadPercent: number;
|
|
}>> {
|
|
const { rows } = await pool.query<{
|
|
table: string;
|
|
dead_tuples: string;
|
|
live_tuples: string;
|
|
dead_percent: string;
|
|
}>(
|
|
`SELECT
|
|
schemaname || '.' || tablename as table,
|
|
n_dead_tup as dead_tuples,
|
|
n_live_tup as live_tuples,
|
|
CASE
|
|
WHEN n_live_tup > 0
|
|
THEN (n_dead_tup::numeric / (n_live_tup + n_dead_tup) * 100)::numeric(5,2)
|
|
ELSE 0
|
|
END as dead_percent
|
|
FROM pg_stat_user_tables
|
|
WHERE n_dead_tup > 1000 -- Only show tables with significant dead tuples
|
|
ORDER BY dead_percent DESC
|
|
LIMIT 10`
|
|
);
|
|
|
|
return rows.map(row => ({
|
|
table: row.table,
|
|
deadTuples: parseInt(row.dead_tuples) || 0,
|
|
liveTuples: parseInt(row.live_tuples) || 0,
|
|
deadPercent: parseFloat(row.dead_percent) || 0
|
|
}));
|
|
}
|
|
|
|
/**
|
|
* Recommend VACUUM if dead tuple percentage > 20%
|
|
*/
|
|
export async function shouldVacuum(): Promise<boolean> {
|
|
const candidates = await getVacuumCandidates();
|
|
return candidates.some(table => table.deadPercent > 20);
|
|
}
|