- Rename asn_peerings table to peerings - Change columns from from_asn_id/to_asn_id to as_a/as_b (integers) - Remove foreign key constraints to asns table - Update RecordPeering to use AS numbers directly - Add validation in RecordPeering to ensure: - Both AS numbers are > 0 - AS numbers are different - as_a is always lower than as_b (normalized) - Update PeeringHandler to no longer need ASN cache - Simplify the code by removing unnecessary ASN lookups
89 lines
3.0 KiB
SQL
89 lines
3.0 KiB
SQL
CREATE TABLE IF NOT EXISTS asns (
|
|
id TEXT PRIMARY KEY,
|
|
number INTEGER UNIQUE NOT NULL,
|
|
handle TEXT,
|
|
description TEXT,
|
|
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 peerings (
|
|
id TEXT PRIMARY KEY,
|
|
as_a INTEGER NOT NULL,
|
|
as_b INTEGER NOT NULL,
|
|
first_seen DATETIME NOT NULL,
|
|
last_seen DATETIME NOT NULL,
|
|
UNIQUE(as_a, as_b)
|
|
);
|
|
|
|
-- 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
|
|
);
|
|
|
|
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_peerings_as_a ON peerings(as_a);
|
|
CREATE INDEX IF NOT EXISTS idx_peerings_as_b ON peerings(as_b);
|
|
CREATE INDEX IF NOT EXISTS idx_peerings_lookup ON peerings(as_a, as_b);
|
|
|
|
-- 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);
|
|
|
|
-- Live routing table maintained by PrefixHandler
|
|
CREATE TABLE IF NOT EXISTS live_routes (
|
|
id TEXT PRIMARY KEY,
|
|
prefix TEXT NOT NULL,
|
|
mask_length INTEGER NOT NULL, -- CIDR mask length (0-32 for IPv4, 0-128 for IPv6)
|
|
ip_version INTEGER NOT NULL, -- 4 or 6
|
|
origin_asn INTEGER NOT NULL,
|
|
peer_ip TEXT NOT NULL,
|
|
as_path TEXT NOT NULL, -- JSON array
|
|
next_hop TEXT NOT NULL,
|
|
last_updated DATETIME NOT NULL,
|
|
UNIQUE(prefix, origin_asn, peer_ip)
|
|
);
|
|
|
|
-- Indexes for live_routes table
|
|
CREATE INDEX IF NOT EXISTS idx_live_routes_prefix ON live_routes(prefix);
|
|
CREATE INDEX IF NOT EXISTS idx_live_routes_mask_length ON live_routes(mask_length);
|
|
CREATE INDEX IF NOT EXISTS idx_live_routes_ip_version_mask ON live_routes(ip_version, mask_length);
|
|
CREATE INDEX IF NOT EXISTS idx_live_routes_last_updated ON live_routes(last_updated); |