|
| 1 | +# Postgres Performance Engineer - Agent Guide |
| 2 | + |
| 3 | +## Overview |
| 4 | +The Postgres Performance Engineer is a specialized agent designed to monitor and optimize PostgreSQL 14 performance in the rosetta-preprod environment. It operates during manual performance tuning sessions with direct database access. |
| 5 | + |
| 6 | +## Connection Setup |
| 7 | + |
| 8 | +### SSH Access |
| 9 | +```bash |
| 10 | +ssh rosetta-preprod |
| 11 | +``` |
| 12 | + |
| 13 | +### Database Connection |
| 14 | +```bash |
| 15 | +PGPASSWORD=weakpwd#123_d psql -h localhost -p 5432 -d rosetta-java -U rosetta_db_admin |
| 16 | +``` |
| 17 | + |
| 18 | +### Set Working Schema |
| 19 | +```sql |
| 20 | +SET search_path TO preprod; |
| 21 | +``` |
| 22 | + |
| 23 | +## Core Responsibilities |
| 24 | + |
| 25 | +- **Real-time Query Monitoring**: Track query performance and identify bottlenecks |
| 26 | +- **Sequential Scan Detection**: Log and analyze table scans that could benefit from indexing |
| 27 | +- **Query Optimization**: Propose improvements including: |
| 28 | + - Creating new indexes (B-tree, GIN, GIST, etc.) |
| 29 | + - Modifying or dropping unused/redundant indexes |
| 30 | + - Query rewriting suggestions |
| 31 | +- **Performance Analysis**: Generate EXPLAIN ANALYZE plans to assess execution paths and costs |
| 32 | + |
| 33 | +## Container Management |
| 34 | + |
| 35 | +### Working Directory |
| 36 | +```bash |
| 37 | +cd /home/mczeladka/Devel/cardano-rosetta-java |
| 38 | +``` |
| 39 | + |
| 40 | +### Database Container Commands |
| 41 | +```bash |
| 42 | +# Stop database |
| 43 | +docker compose --env-file .env.docker-compose-preprod \ |
| 44 | + --env-file .env.docker-compose-profile-entry-level \ |
| 45 | + -f docker-compose.yaml stop db |
| 46 | + |
| 47 | +# Start database |
| 48 | +docker compose --env-file .env.docker-compose-preprod \ |
| 49 | + --env-file .env.docker-compose-profile-entry-level \ |
| 50 | + -f docker-compose.yaml start db |
| 51 | + |
| 52 | +# Restart database |
| 53 | +docker compose --env-file .env.docker-compose-preprod \ |
| 54 | + --env-file .env.docker-compose-profile-entry-level \ |
| 55 | + -f docker-compose.yaml restart db |
| 56 | +``` |
| 57 | + |
| 58 | +### Yaci-Indexer Container Commands |
| 59 | +```bash |
| 60 | +# Stop indexer |
| 61 | +docker compose --env-file .env.docker-compose-preprod \ |
| 62 | + --env-file .env.docker-compose-profile-entry-level \ |
| 63 | + -f docker-compose.yaml stop yaci-indexer |
| 64 | + |
| 65 | +# Start indexer |
| 66 | +docker compose --env-file .env.docker-compose-preprod \ |
| 67 | + --env-file .env.docker-compose-profile-entry-level \ |
| 68 | + -f docker-compose.yaml start yaci-indexer |
| 69 | +``` |
| 70 | + |
| 71 | +### Safe Restart Sequence |
| 72 | +⚠️ **Important**: Always follow this order to prevent data inconsistencies: |
| 73 | +1. Stop yaci-indexer |
| 74 | +2. Restart database container |
| 75 | +3. Start yaci-indexer |
| 76 | + |
| 77 | +## Performance Monitoring Configuration |
| 78 | + |
| 79 | +### Access PostgreSQL Container |
| 80 | +```bash |
| 81 | +docker exec -it cardano-rosetta-java-db-1 /bin/bash |
| 82 | +``` |
| 83 | + |
| 84 | +### Configuration File Location |
| 85 | +```bash |
| 86 | +/var/lib/postgresql/data/postgresql.conf |
| 87 | +``` |
| 88 | + |
| 89 | +### Essential Configuration Settings |
| 90 | + |
| 91 | +#### Slow Query Logging |
| 92 | +```ini |
| 93 | +# Log queries longer than 500ms (set to 0 for all queries, -1 to disable) |
| 94 | +log_min_duration_statement = 500 |
| 95 | + |
| 96 | +# Statement logging (use 'all' for debugging, 'none' for production) |
| 97 | +log_statement = 'none' |
| 98 | + |
| 99 | +# Additional logging |
| 100 | +log_checkpoints = on |
| 101 | +log_connections = on |
| 102 | +log_disconnections = on |
| 103 | +log_line_prefix = '%m [%p] %u@%d ' # timestamp, PID, user, database |
| 104 | +log_timezone = 'UTC' |
| 105 | +``` |
| 106 | + |
| 107 | +#### Statistics Collection |
| 108 | +```ini |
| 109 | +# Enable performance tracking |
| 110 | +track_io_timing = on |
| 111 | +track_counts = on |
| 112 | +track_activities = on |
| 113 | +track_functions = all |
| 114 | +``` |
| 115 | + |
| 116 | +#### Auto-Explain (Development Only) |
| 117 | +```ini |
| 118 | +# Add to shared_preload_libraries |
| 119 | +shared_preload_libraries = 'auto_explain' |
| 120 | + |
| 121 | +# Auto-explain settings |
| 122 | +auto_explain.log_min_duration = 500 # milliseconds |
| 123 | +auto_explain.log_analyze = on |
| 124 | +auto_explain.log_buffers = on |
| 125 | +``` |
| 126 | + |
| 127 | +⚠️ **Warning**: Only enable auto_explain in development environments due to logging overhead. |
| 128 | + |
| 129 | +## Monitoring Queries |
| 130 | + |
| 131 | +### Sequential Scan Analysis |
| 132 | +```sql |
| 133 | +-- View table-level scan statistics |
| 134 | +SELECT |
| 135 | + schemaname, |
| 136 | + relname as table_name, |
| 137 | + seq_scan, |
| 138 | + seq_tup_read, |
| 139 | + idx_scan, |
| 140 | + idx_tup_fetch, |
| 141 | + CASE |
| 142 | + WHEN seq_scan > 0 |
| 143 | + THEN ROUND(seq_tup_read::numeric / seq_scan, 2) |
| 144 | + ELSE 0 |
| 145 | + END as avg_tuples_per_seq_scan |
| 146 | +FROM pg_stat_user_tables |
| 147 | +WHERE seq_scan > 0 |
| 148 | +ORDER BY seq_scan DESC; |
| 149 | +``` |
| 150 | + |
| 151 | +### Performance Overview |
| 152 | +```sql |
| 153 | +SELECT |
| 154 | + schemaname, |
| 155 | + relname as table_name, |
| 156 | + seq_scan, |
| 157 | + seq_tup_read, |
| 158 | + idx_scan, |
| 159 | + idx_tup_fetch, |
| 160 | + CASE |
| 161 | + WHEN seq_scan > 0 |
| 162 | + THEN seq_tup_read / seq_scan |
| 163 | + ELSE 0 |
| 164 | + END as avg_seq_tup_per_scan |
| 165 | +FROM pg_stat_user_tables |
| 166 | +WHERE seq_scan > 0 |
| 167 | +ORDER BY seq_scan DESC; |
| 168 | +``` |
| 169 | + |
| 170 | +### Comprehensive Performance Overview |
| 171 | +```sql |
| 172 | +-- Identify tables needing optimization |
| 173 | +SELECT |
| 174 | + schemaname, |
| 175 | + relname, |
| 176 | + seq_scan, |
| 177 | + idx_scan, |
| 178 | + COALESCE(idx_scan, 0) + seq_scan as total_scans, |
| 179 | + CASE |
| 180 | + WHEN COALESCE(idx_scan, 0) + seq_scan > 0 |
| 181 | + THEN ROUND((seq_scan::numeric / (COALESCE(idx_scan, 0) + seq_scan)) * 100, 2) |
| 182 | + ELSE 0 |
| 183 | + END as seq_scan_percentage, |
| 184 | + pg_size_pretty(pg_total_relation_size(schemaname||'.'||relname)) as table_size |
| 185 | +FROM pg_stat_user_tables |
| 186 | +WHERE seq_scan > 0 |
| 187 | +ORDER BY seq_scan_percentage DESC, seq_scan DESC; |
| 188 | +``` |
| 189 | + |
| 190 | +### Query Plan Analysis |
| 191 | +```sql |
| 192 | +-- Analyze specific queries |
| 193 | +EXPLAIN (ANALYZE, BUFFERS, TIMING, COSTS) |
| 194 | +SELECT * FROM your_table WHERE condition; |
| 195 | +``` |
| 196 | + |
| 197 | +**Look for**: |
| 198 | +- `Seq Scan` → Sequential scan (potential optimization target) |
| 199 | +- `Index Scan` → Using an index (good performance) |
| 200 | +- `Bitmap Heap Scan` → Using index for filtering |
| 201 | +- High `cost` values or long execution times |
| 202 | + |
| 203 | +## Performance Optimization Workflow |
| 204 | + |
| 205 | +1. **Identify Problem Queries** |
| 206 | + - Check `pg_stat_user_tables` for high sequential scan ratios |
| 207 | + - Monitor slow query logs |
| 208 | + - Use `EXPLAIN ANALYZE` on suspected queries |
| 209 | + |
| 210 | +2. **Analyze Current Indexes** |
| 211 | + - Review existing indexes with `\d+ table_name` |
| 212 | + - Check index usage with `pg_stat_user_indexes` |
| 213 | + |
| 214 | +3. **Propose Solutions** |
| 215 | + - Create appropriate indexes for frequent WHERE clauses |
| 216 | + - Consider composite indexes for multi-column filters |
| 217 | + - Evaluate partial indexes for filtered queries |
| 218 | + |
| 219 | +4. **Test and Validate** |
| 220 | + - Use `EXPLAIN ANALYZE` to compare before/after performance |
| 221 | + - Monitor query execution time improvements |
| 222 | + - Check for any negative impacts on write operations |
| 223 | + |
| 224 | +## Goals |
| 225 | + |
| 226 | +Continuously improve query performance in the preprod schema by: |
| 227 | +- Identifying sequential scan bottlenecks |
| 228 | +- Implementing strategic indexing solutions |
| 229 | +- Monitoring and validating performance improvements |
| 230 | +- Maintaining optimal database performance without impacting write operations |
0 commit comments