- Add covering index for SELECT id queries (avoids table lookups) - Add stats index for COUNT queries on live_routes - Add index on asns.number for ASN lookups - Add index on bgp_peers.peer_ip for peer lookups These indexes should further reduce query times, especially: - The covering index includes the id column, eliminating the need to access the table after index lookup - The stats index helps with COUNT(*) queries - The asns.number index speeds up ASN lookups in transactions
116 lines
3.8 KiB
SQL
116 lines
3.8 KiB
SQL
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;
|
|
|
|
-- Covering index for SELECT id queries (includes id in index)
|
|
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 stats queries
|
|
CREATE INDEX IF NOT EXISTS idx_live_routes_stats
|
|
ON live_routes(withdrawn_at)
|
|
WHERE withdrawn_at IS NULL;
|
|
|
|
-- Additional indexes for prefixes table
|
|
CREATE INDEX IF NOT EXISTS idx_prefixes_prefix ON prefixes(prefix);
|
|
|
|
-- Indexes for asns table
|
|
CREATE INDEX IF NOT EXISTS idx_asns_number ON asns(number);
|
|
|
|
-- 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);
|
|
CREATE INDEX IF NOT EXISTS idx_bgp_peers_ip ON bgp_peers(peer_ip); |