diff --git a/internal/database/database.go b/internal/database/database.go index ad315c8..7d28be3 100644 --- a/internal/database/database.go +++ b/internal/database/database.go @@ -95,7 +95,8 @@ func NewWithConfig(config Config, logger *slog.Logger) (*Database, error) { } // Add connection parameters for modernc.org/sqlite - dsn := fmt.Sprintf("file:%s?_busy_timeout=5000&_journal_mode=WAL", config.Path) + // Enable WAL mode and other performance optimizations + dsn := fmt.Sprintf("file:%s?_busy_timeout=5000&_journal_mode=WAL&_synchronous=NORMAL&_cache_size=-512000", config.Path) db, err := sql.Open("sqlite", dsn) if err != nil { return nil, fmt.Errorf("failed to open database: %w", err) @@ -123,12 +124,14 @@ func NewWithConfig(config Config, logger *slog.Logger) (*Database, error) { func (d *Database) Initialize() error { // Set SQLite pragmas for better performance pragmas := []string{ - "PRAGMA journal_mode=WAL", // Already set in connection string - "PRAGMA synchronous=NORMAL", // Faster than FULL, still safe - "PRAGMA cache_size=-524288", // 512MB cache - "PRAGMA temp_store=MEMORY", // Use memory for temp tables - "PRAGMA mmap_size=268435456", // 256MB memory-mapped I/O - "PRAGMA optimize", // Run optimizer + "PRAGMA journal_mode=WAL", // Already set in connection string + "PRAGMA synchronous=NORMAL", // Faster than FULL, still safe + "PRAGMA cache_size=-524288", // 512MB cache + "PRAGMA temp_store=MEMORY", // Use memory for temp tables + "PRAGMA mmap_size=268435456", // 256MB memory-mapped I/O + "PRAGMA wal_autocheckpoint=1000", // Checkpoint every 1000 pages + "PRAGMA wal_checkpoint(PASSIVE)", // Checkpoint now + "PRAGMA optimize", // Run optimizer } for _, pragma := range pragmas { @@ -344,33 +347,18 @@ func (d *Database) UpdateLiveRoute( nextHop string, timestamp time.Time, ) error { - // Check if route already exists - var routeID sql.NullString - err := d.queryRow(` - SELECT id FROM live_routes - WHERE prefix_id = ? AND origin_asn_id = ? AND peer_asn = ? AND withdrawn_at IS NULL`, - prefixID.String(), originASNID.String(), peerASN).Scan(&routeID) - - if err != nil && err != sql.ErrNoRows { - return err - } - - if routeID.Valid { - // Route exists and is active, update it - err = d.exec(` - UPDATE live_routes - SET next_hop = ?, announced_at = ? - WHERE id = ?`, - nextHop, timestamp, routeID.String) - } else { - // Either new route or re-announcement of withdrawn route - err = d.exec(` - INSERT OR REPLACE INTO live_routes - (id, prefix_id, origin_asn_id, peer_asn, next_hop, announced_at, withdrawn_at) - VALUES (?, ?, ?, ?, ?, ?, NULL)`, - generateUUID().String(), prefixID.String(), originASNID.String(), - peerASN, nextHop, timestamp) - } + // Use SQLite's UPSERT capability to avoid the SELECT+UPDATE/INSERT pattern + // This reduces the number of queries and improves performance + err := d.exec(` + INSERT INTO live_routes (id, prefix_id, origin_asn_id, peer_asn, next_hop, announced_at, withdrawn_at) + VALUES (?, ?, ?, ?, ?, ?, NULL) + ON CONFLICT(prefix_id, origin_asn_id, peer_asn) DO UPDATE SET + next_hop = excluded.next_hop, + announced_at = excluded.announced_at, + withdrawn_at = NULL + WHERE withdrawn_at IS NULL`, + generateUUID().String(), prefixID.String(), originASNID.String(), + peerASN, nextHop, timestamp) return err } diff --git a/internal/database/schema.sql b/internal/database/schema.sql index a3625cc..eccf426 100644 --- a/internal/database/schema.sql +++ b/internal/database/schema.sql @@ -99,6 +99,10 @@ CREATE INDEX IF NOT EXISTS idx_live_routes_covering ON live_routes(prefix_id, origin_asn_id, peer_asn, id) WHERE withdrawn_at IS NULL; +-- Index for UPDATE by id operations +CREATE INDEX IF NOT EXISTS idx_live_routes_id + ON live_routes(id); + -- Index for stats queries CREATE INDEX IF NOT EXISTS idx_live_routes_stats ON live_routes(withdrawn_at)