Extract database schema to separate SQL file
- Move schema from database.go to schema.sql - Use go:embed to include schema at compile time - Add 'out' debug file to .gitignore This makes the schema more maintainable and easier to review.
This commit is contained in:
parent
97a06e14f2
commit
4a3d71d307
5
.gitignore
vendored
5
.gitignore
vendored
@ -31,4 +31,7 @@ go.work.sum
|
||||
*.tmp
|
||||
|
||||
# Raw AS data (we only commit the gzipped version)
|
||||
pkg/asinfo/asdata.json
|
||||
pkg/asinfo/asdata.json
|
||||
|
||||
# Debug output files
|
||||
out
|
@ -3,6 +3,7 @@ package database
|
||||
|
||||
import (
|
||||
"database/sql"
|
||||
_ "embed"
|
||||
"fmt"
|
||||
"log/slog"
|
||||
"os"
|
||||
@ -14,113 +15,10 @@ import (
|
||||
_ "modernc.org/sqlite" // Pure Go SQLite driver
|
||||
)
|
||||
|
||||
const (
|
||||
dirPermissions = 0750 // rwxr-x---
|
||||
dbSchema = `
|
||||
CREATE TABLE IF NOT EXISTS asns (
|
||||
id TEXT PRIMARY KEY,
|
||||
number INTEGER UNIQUE NOT NULL,
|
||||
first_seen DATETIME NOT NULL,
|
||||
last_seen DATETIME NOT NULL
|
||||
);
|
||||
//go:embed schema.sql
|
||||
var dbSchema string
|
||||
|
||||
CREATE TABLE IF NOT EXISTS prefixes (
|
||||
id TEXT PRIMARY KEY,
|
||||
prefix TEXT UNIQUE NOT NULL,
|
||||
ip_version INTEGER NOT NULL, -- 4 for IPv4, 6 for IPv6
|
||||
first_seen DATETIME NOT NULL,
|
||||
last_seen DATETIME NOT NULL
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS announcements (
|
||||
id TEXT PRIMARY KEY,
|
||||
prefix_id TEXT NOT NULL,
|
||||
asn_id TEXT NOT NULL,
|
||||
origin_asn_id TEXT NOT NULL,
|
||||
path TEXT NOT NULL,
|
||||
next_hop TEXT,
|
||||
timestamp DATETIME NOT NULL,
|
||||
is_withdrawal BOOLEAN NOT NULL DEFAULT 0,
|
||||
FOREIGN KEY (prefix_id) REFERENCES prefixes(id),
|
||||
FOREIGN KEY (asn_id) REFERENCES asns(id),
|
||||
FOREIGN KEY (origin_asn_id) REFERENCES asns(id)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS asn_peerings (
|
||||
id TEXT PRIMARY KEY,
|
||||
from_asn_id TEXT NOT NULL,
|
||||
to_asn_id TEXT NOT NULL,
|
||||
first_seen DATETIME NOT NULL,
|
||||
last_seen DATETIME NOT NULL,
|
||||
FOREIGN KEY (from_asn_id) REFERENCES asns(id),
|
||||
FOREIGN KEY (to_asn_id) REFERENCES asns(id),
|
||||
UNIQUE(from_asn_id, to_asn_id)
|
||||
);
|
||||
|
||||
-- BGP peers that send us messages
|
||||
CREATE TABLE IF NOT EXISTS bgp_peers (
|
||||
id TEXT PRIMARY KEY,
|
||||
peer_ip TEXT UNIQUE NOT NULL,
|
||||
peer_asn INTEGER NOT NULL,
|
||||
first_seen DATETIME NOT NULL,
|
||||
last_seen DATETIME NOT NULL,
|
||||
last_message_type TEXT
|
||||
);
|
||||
|
||||
-- Live routing table: current state of announced routes
|
||||
CREATE TABLE IF NOT EXISTS live_routes (
|
||||
id TEXT PRIMARY KEY,
|
||||
prefix_id TEXT NOT NULL,
|
||||
origin_asn_id TEXT NOT NULL,
|
||||
peer_asn INTEGER NOT NULL,
|
||||
next_hop TEXT,
|
||||
announced_at DATETIME NOT NULL,
|
||||
withdrawn_at DATETIME,
|
||||
FOREIGN KEY (prefix_id) REFERENCES prefixes(id),
|
||||
FOREIGN KEY (origin_asn_id) REFERENCES asns(id),
|
||||
UNIQUE(prefix_id, origin_asn_id, peer_asn)
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_prefixes_ip_version ON prefixes(ip_version);
|
||||
CREATE INDEX IF NOT EXISTS idx_prefixes_version_prefix ON prefixes(ip_version, prefix);
|
||||
CREATE INDEX IF NOT EXISTS idx_announcements_timestamp ON announcements(timestamp);
|
||||
CREATE INDEX IF NOT EXISTS idx_announcements_prefix_id ON announcements(prefix_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_announcements_asn_id ON announcements(asn_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_asn_peerings_from_asn ON asn_peerings(from_asn_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_asn_peerings_to_asn ON asn_peerings(to_asn_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_asn_peerings_lookup ON asn_peerings(from_asn_id, to_asn_id);
|
||||
|
||||
-- Indexes for live routes table
|
||||
CREATE INDEX IF NOT EXISTS idx_live_routes_active
|
||||
ON live_routes(prefix_id, origin_asn_id)
|
||||
WHERE withdrawn_at IS NULL;
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_live_routes_origin
|
||||
ON live_routes(origin_asn_id)
|
||||
WHERE withdrawn_at IS NULL;
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_live_routes_prefix
|
||||
ON live_routes(prefix_id)
|
||||
WHERE withdrawn_at IS NULL;
|
||||
|
||||
-- Critical index for the most common query pattern
|
||||
CREATE INDEX IF NOT EXISTS idx_live_routes_lookup
|
||||
ON live_routes(prefix_id, origin_asn_id, peer_asn)
|
||||
WHERE withdrawn_at IS NULL;
|
||||
|
||||
-- Index for withdrawal updates by prefix and peer
|
||||
CREATE INDEX IF NOT EXISTS idx_live_routes_withdraw
|
||||
ON live_routes(prefix_id, peer_asn)
|
||||
WHERE withdrawn_at IS NULL;
|
||||
|
||||
-- Additional indexes for prefixes table
|
||||
CREATE INDEX IF NOT EXISTS idx_prefixes_prefix ON prefixes(prefix);
|
||||
|
||||
-- Indexes for bgp_peers table
|
||||
CREATE INDEX IF NOT EXISTS idx_bgp_peers_asn ON bgp_peers(peer_asn);
|
||||
CREATE INDEX IF NOT EXISTS idx_bgp_peers_last_seen ON bgp_peers(last_seen);
|
||||
`
|
||||
)
|
||||
const dirPermissions = 0750 // rwxr-x---
|
||||
|
||||
// Database manages the SQLite database connection and operations.
|
||||
type Database struct {
|
||||
|
102
internal/database/schema.sql
Normal file
102
internal/database/schema.sql
Normal file
@ -0,0 +1,102 @@
|
||||
CREATE TABLE IF NOT EXISTS asns (
|
||||
id TEXT PRIMARY KEY,
|
||||
number INTEGER UNIQUE NOT NULL,
|
||||
first_seen DATETIME NOT NULL,
|
||||
last_seen DATETIME NOT NULL
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS prefixes (
|
||||
id TEXT PRIMARY KEY,
|
||||
prefix TEXT UNIQUE NOT NULL,
|
||||
ip_version INTEGER NOT NULL, -- 4 for IPv4, 6 for IPv6
|
||||
first_seen DATETIME NOT NULL,
|
||||
last_seen DATETIME NOT NULL
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS announcements (
|
||||
id TEXT PRIMARY KEY,
|
||||
prefix_id TEXT NOT NULL,
|
||||
asn_id TEXT NOT NULL,
|
||||
origin_asn_id TEXT NOT NULL,
|
||||
path TEXT NOT NULL,
|
||||
next_hop TEXT,
|
||||
timestamp DATETIME NOT NULL,
|
||||
is_withdrawal BOOLEAN NOT NULL DEFAULT 0,
|
||||
FOREIGN KEY (prefix_id) REFERENCES prefixes(id),
|
||||
FOREIGN KEY (asn_id) REFERENCES asns(id),
|
||||
FOREIGN KEY (origin_asn_id) REFERENCES asns(id)
|
||||
);
|
||||
|
||||
CREATE TABLE IF NOT EXISTS asn_peerings (
|
||||
id TEXT PRIMARY KEY,
|
||||
from_asn_id TEXT NOT NULL,
|
||||
to_asn_id TEXT NOT NULL,
|
||||
first_seen DATETIME NOT NULL,
|
||||
last_seen DATETIME NOT NULL,
|
||||
FOREIGN KEY (from_asn_id) REFERENCES asns(id),
|
||||
FOREIGN KEY (to_asn_id) REFERENCES asns(id),
|
||||
UNIQUE(from_asn_id, to_asn_id)
|
||||
);
|
||||
|
||||
-- BGP peers that send us messages
|
||||
CREATE TABLE IF NOT EXISTS bgp_peers (
|
||||
id TEXT PRIMARY KEY,
|
||||
peer_ip TEXT UNIQUE NOT NULL,
|
||||
peer_asn INTEGER NOT NULL,
|
||||
first_seen DATETIME NOT NULL,
|
||||
last_seen DATETIME NOT NULL,
|
||||
last_message_type TEXT
|
||||
);
|
||||
|
||||
-- Live routing table: current state of announced routes
|
||||
CREATE TABLE IF NOT EXISTS live_routes (
|
||||
id TEXT PRIMARY KEY,
|
||||
prefix_id TEXT NOT NULL,
|
||||
origin_asn_id TEXT NOT NULL,
|
||||
peer_asn INTEGER NOT NULL,
|
||||
next_hop TEXT,
|
||||
announced_at DATETIME NOT NULL,
|
||||
withdrawn_at DATETIME,
|
||||
FOREIGN KEY (prefix_id) REFERENCES prefixes(id),
|
||||
FOREIGN KEY (origin_asn_id) REFERENCES asns(id),
|
||||
UNIQUE(prefix_id, origin_asn_id, peer_asn)
|
||||
);
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_prefixes_ip_version ON prefixes(ip_version);
|
||||
CREATE INDEX IF NOT EXISTS idx_prefixes_version_prefix ON prefixes(ip_version, prefix);
|
||||
CREATE INDEX IF NOT EXISTS idx_announcements_timestamp ON announcements(timestamp);
|
||||
CREATE INDEX IF NOT EXISTS idx_announcements_prefix_id ON announcements(prefix_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_announcements_asn_id ON announcements(asn_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_asn_peerings_from_asn ON asn_peerings(from_asn_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_asn_peerings_to_asn ON asn_peerings(to_asn_id);
|
||||
CREATE INDEX IF NOT EXISTS idx_asn_peerings_lookup ON asn_peerings(from_asn_id, to_asn_id);
|
||||
|
||||
-- Indexes for live routes table
|
||||
CREATE INDEX IF NOT EXISTS idx_live_routes_active
|
||||
ON live_routes(prefix_id, origin_asn_id)
|
||||
WHERE withdrawn_at IS NULL;
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_live_routes_origin
|
||||
ON live_routes(origin_asn_id)
|
||||
WHERE withdrawn_at IS NULL;
|
||||
|
||||
CREATE INDEX IF NOT EXISTS idx_live_routes_prefix
|
||||
ON live_routes(prefix_id)
|
||||
WHERE withdrawn_at IS NULL;
|
||||
|
||||
-- Critical index for the most common query pattern
|
||||
CREATE INDEX IF NOT EXISTS idx_live_routes_lookup
|
||||
ON live_routes(prefix_id, origin_asn_id, peer_asn)
|
||||
WHERE withdrawn_at IS NULL;
|
||||
|
||||
-- Index for withdrawal updates by prefix and peer
|
||||
CREATE INDEX IF NOT EXISTS idx_live_routes_withdraw
|
||||
ON live_routes(prefix_id, peer_asn)
|
||||
WHERE withdrawn_at IS NULL;
|
||||
|
||||
-- Additional indexes for prefixes table
|
||||
CREATE INDEX IF NOT EXISTS idx_prefixes_prefix ON prefixes(prefix);
|
||||
|
||||
-- Indexes for bgp_peers table
|
||||
CREATE INDEX IF NOT EXISTS idx_bgp_peers_asn ON bgp_peers(peer_asn);
|
||||
CREATE INDEX IF NOT EXISTS idx_bgp_peers_last_seen ON bgp_peers(last_seen);
|
Loading…
Reference in New Issue
Block a user