1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
|
---
description: Monitor vector search performance and index efficiency for the memory MCP server
allowed-tools: Bash, Read, Grep
---
# Performance Monitoring Command
Monitor and analyze the performance of vector search operations, index efficiency, and memory lifecycle metrics.
## Usage
This command provides comprehensive performance monitoring for:
- Vector search query performance
- Index usage and efficiency
- Memory lifecycle statistics
- Database query patterns
- Resource utilization
## Available Monitoring Tasks
### 1. Vector Search Performance
```bash
# Check current pgvector index statistics
psql $DATABASE_URL -c "
SELECT
schemaname,
tablename,
indexname,
idx_scan as index_scans,
idx_tup_read as tuples_read,
idx_tup_fetch as tuples_fetched,
pg_size_pretty(pg_relation_size(indexrelid)) as index_size
FROM pg_stat_user_indexes
WHERE indexname LIKE '%vector%' OR indexname LIKE '%embedding%'
ORDER BY idx_scan DESC;
"
# Analyze query performance for vector operations
psql $DATABASE_URL -c "
SELECT
substring(query, 1, 50) as query_preview,
calls,
mean_exec_time as avg_ms,
min_exec_time as min_ms,
max_exec_time as max_ms,
total_exec_time as total_ms,
rows
FROM pg_stat_statements
WHERE query LIKE '%embedding%' OR query LIKE '%vector%'
ORDER BY mean_exec_time DESC
LIMIT 20;
"
```
### 2. Index Efficiency Analysis
```bash
# Check IVFFlat index clustering quality
psql $DATABASE_URL -c "
SELECT
indexname,
lists,
pages,
tuples,
ROUND(tuples::numeric / NULLIF(lists, 0), 2) as avg_vectors_per_list,
CASE
WHEN tuples::numeric / NULLIF(lists, 0) > 10000 THEN 'Rebalance recommended'
WHEN tuples::numeric / NULLIF(lists, 0) < 100 THEN 'Over-partitioned'
ELSE 'Optimal'
END as status
FROM (
SELECT
'memories_embedding_ivfflat_idx'::regclass as indexname,
(SELECT current_setting('ivfflat.lists')::int) as lists,
relpages as pages,
reltuples as tuples
FROM pg_class
WHERE oid = 'memories_embedding_ivfflat_idx'::regclass
) index_stats;
"
# Check HNSW index parameters
psql $DATABASE_URL -c "
SELECT
indexname,
m,
ef_construction,
ef_search,
CASE
WHEN ef_search < 100 THEN 'Low recall configuration'
WHEN ef_search > 500 THEN 'High cost configuration'
ELSE 'Balanced configuration'
END as configuration_assessment
FROM (
SELECT
'memories_embedding_hnsw_idx' as indexname,
current_setting('hnsw.m')::int as m,
current_setting('hnsw.ef_construction')::int as ef_construction,
current_setting('hnsw.ef_search')::int as ef_search
) hnsw_config;
"
```
### 3. Memory Lifecycle Metrics
```bash
# Memory distribution by status and type
psql $DATABASE_URL -c "
SELECT
type,
COUNT(*) FILTER (WHERE is_archived = false) as active,
COUNT(*) FILTER (WHERE is_archived = true) as archived,
AVG(importance) as avg_importance,
AVG(access_count) as avg_accesses,
AVG(EXTRACT(EPOCH FROM (NOW() - created_at)) / 86400)::int as avg_age_days
FROM memories
GROUP BY type
ORDER BY active DESC;
"
# Memory expiration analysis
psql $DATABASE_URL -c "
SELECT
CASE
WHEN expires_at IS NULL THEN 'Never expires'
WHEN expires_at < NOW() THEN 'Expired'
WHEN expires_at < NOW() + INTERVAL '7 days' THEN 'Expiring soon'
WHEN expires_at < NOW() + INTERVAL '30 days' THEN 'Expiring this month'
ELSE 'Long-term'
END as expiration_status,
COUNT(*) as count,
AVG(importance) as avg_importance
FROM memories
WHERE is_archived = false
GROUP BY expiration_status
ORDER BY count DESC;
"
# Consolidation statistics
psql $DATABASE_URL -c "
SELECT
relation_type,
COUNT(*) as relationship_count,
COUNT(DISTINCT from_memory_id) as source_memories,
COUNT(DISTINCT to_memory_id) as target_memories
FROM memory_relations
WHERE relation_type IN ('consolidated_into', 'summarized_in', 'elaborates', 'corrects')
GROUP BY relation_type;
"
```
### 4. Query Pattern Analysis
```bash
# Analyze search patterns by limit size
psql $DATABASE_URL -c "
WITH query_patterns AS (
SELECT
CASE
WHEN query LIKE '%LIMIT 1%' THEN 'Single result'
WHEN query LIKE '%LIMIT 5%' OR query LIKE '%LIMIT 10%' THEN 'Small batch'
WHEN query LIKE '%LIMIT 50%' OR query LIKE '%LIMIT 100%' THEN 'Large batch'
ELSE 'Variable'
END as pattern,
COUNT(*) as query_count,
AVG(mean_exec_time) as avg_time_ms,
SUM(calls) as total_calls
FROM pg_stat_statements
WHERE query LIKE '%ORDER BY % <=>%' -- Vector similarity queries
GROUP BY pattern
)
SELECT * FROM query_patterns ORDER BY total_calls DESC;
"
# Identify slow queries
psql $DATABASE_URL -c "
SELECT
substring(query, 1, 100) as query_preview,
calls,
mean_exec_time as avg_ms,
max_exec_time as worst_ms,
rows / NULLIF(calls, 0) as avg_rows_returned
FROM pg_stat_statements
WHERE
mean_exec_time > 100 -- Queries slower than 100ms
AND (query LIKE '%memories%' OR query LIKE '%embedding%')
ORDER BY mean_exec_time DESC
LIMIT 10;
"
```
### 5. Storage and Resource Utilization
```bash
# Table and index sizes
psql $DATABASE_URL -c "
SELECT
schemaname,
tablename,
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 index_size,
n_live_tup as row_count,
n_dead_tup as dead_rows,
ROUND(100.0 * n_dead_tup / NULLIF(n_live_tup + n_dead_tup, 0), 2) as dead_percent
FROM pg_stat_user_tables
WHERE tablename IN ('memories', 'memory_relations', 'companions', 'users', 'companion_sessions')
ORDER BY pg_total_relation_size(schemaname||'.'||tablename) DESC;
"
# Embedding storage analysis
psql $DATABASE_URL -c "
SELECT
COUNT(*) as total_memories,
COUNT(embedding) as memories_with_embeddings,
pg_size_pretty(
SUM(pg_column_size(embedding))
) as total_embedding_storage,
pg_size_pretty(
AVG(pg_column_size(embedding))::bigint
) as avg_embedding_size,
COUNT(*) FILTER (WHERE embedding IS NULL) as missing_embeddings
FROM memories;
"
```
### 6. Real-time Monitoring Dashboard
```bash
# Create a monitoring loop (run for 60 seconds)
echo "Starting real-time performance monitoring for 60 seconds..."
for i in {1..12}; do
clear
echo "=== Memory MCP Server Performance Monitor ==="
echo "Time: $(date '+%Y-%m-%d %H:%M:%S')"
echo ""
# Active connections
psql $DATABASE_URL -t -c "
SELECT 'Active connections: ' || count(*)
FROM pg_stat_activity
WHERE state = 'active';
"
# Recent vector searches
psql $DATABASE_URL -t -c "
SELECT 'Vector searches (last min): ' || count(*)
FROM pg_stat_statements
WHERE query LIKE '%embedding%'
AND last_call > NOW() - INTERVAL '1 minute';
"
# Memory operations
psql $DATABASE_URL -t -c "
SELECT
'Memories created (last hour): ' ||
COUNT(*) FILTER (WHERE created_at > NOW() - INTERVAL '1 hour')
FROM memories;
"
# Cache hit ratio
psql $DATABASE_URL -t -c "
SELECT 'Cache hit ratio: ' ||
ROUND(100.0 * blks_hit / NULLIF(blks_hit + blks_read, 0), 2) || '%'
FROM pg_stat_database
WHERE datname = current_database();
"
sleep 5
done
```
## Performance Tuning Recommendations
Based on monitoring results, consider these optimizations:
### For Slow Vector Searches
- Increase `ivfflat.probes` for better accuracy
- Enable iterative scans: `SET enable_iterative_index_scan = true`
- Consider switching from IVFFlat to HNSW for small result sets
### For Poor Index Performance
- Rebuild IVFFlat indexes if avg_vectors_per_list > 10000
- Increase HNSW `ef_search` for better recall
- Add more specific indexes for common query patterns
### For Memory Lifecycle Issues
- Adjust expiration policies based on usage patterns
- Implement more aggressive consolidation for old memories
- Archive memories with low importance scores
### For Storage Optimization
- Use halfvec type for less critical embeddings
- Implement memory pruning for users exceeding limits
- Compress archived memory content
## Integration with Application
To integrate monitoring into your application:
```typescript
// src/monitoring/performanceMonitor.ts
import { db } from "../db/client";
import { sql } from "drizzle-orm";
export class PerformanceMonitor {
async getVectorSearchMetrics() {
// Implementation based on queries above
}
async getIndexEfficiency() {
// Implementation based on queries above
}
async getMemoryLifecycleStats() {
// Implementation based on queries above
}
}
```
## Automated Alerts
Set up alerts when:
- Average query time exceeds 200ms
- Index scan ratio drops below 90%
- Dead tuple percentage exceeds 20%
- Memory count approaches user limits
- Embedding generation fails repeatedly
## Export Metrics
Export monitoring data for analysis:
```bash
# Export to CSV
psql $DATABASE_URL -c "\COPY (
SELECT * FROM pg_stat_user_indexes WHERE indexname LIKE '%vector%'
) TO '/tmp/index_stats.csv' WITH CSV HEADER;"
# Generate performance report
psql $DATABASE_URL -H -o performance_report.html -c "
-- Your monitoring queries here
"
```
This command provides comprehensive monitoring capabilities for optimizing your memory MCP server's performance.
|