routewatch/internal/database/schema.sql
sneak d2041a5a55 Add WHOIS stats to status page with adaptive fetcher improvements
- Add WHOIS Fetcher card showing fresh/stale/never-fetched ASN counts
- Display hourly success/error counts and current fetch interval
- Increase max WHOIS rate to 1/sec (down from 10 sec minimum)
- Select random stale ASN instead of oldest for better distribution
- Add index on whois_updated_at for query performance
- Track success/error timestamps for hourly stats
- Add GetWHOISStats database method for freshness statistics
2025-12-27 16:20:09 +07:00

146 lines
5.3 KiB
SQL

-- IMPORTANT: This is the ONLY place where schema changes should be made.
-- We do NOT support migrations. All schema changes MUST be in this file.
-- DO NOT make schema changes anywhere else in the codebase.
CREATE TABLE IF NOT EXISTS asns (
asn INTEGER PRIMARY KEY,
handle TEXT,
description TEXT,
-- WHOIS parsed fields
as_name TEXT,
org_name TEXT,
org_id TEXT,
address TEXT, -- full address (may be multi-line)
country_code TEXT,
abuse_email TEXT,
abuse_phone TEXT,
tech_email TEXT,
tech_phone TEXT,
rir TEXT, -- ARIN, RIPE, APNIC, LACNIC, AFRINIC
rir_registration_date DATETIME,
rir_last_modified DATETIME,
-- Raw WHOIS response
whois_raw TEXT, -- complete WHOIS response text
-- Timestamps
first_seen DATETIME NOT NULL,
last_seen DATETIME NOT NULL,
whois_updated_at DATETIME -- when we last fetched WHOIS data
);
-- IPv4 prefixes table
CREATE TABLE IF NOT EXISTS prefixes_v4 (
id TEXT PRIMARY KEY,
prefix TEXT UNIQUE NOT NULL,
first_seen DATETIME NOT NULL,
last_seen DATETIME NOT NULL
);
-- IPv6 prefixes table
CREATE TABLE IF NOT EXISTS prefixes_v6 (
id TEXT PRIMARY KEY,
prefix TEXT UNIQUE NOT NULL,
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,
peer_asn INTEGER NOT NULL,
origin_asn INTEGER NOT NULL,
path TEXT NOT NULL,
next_hop TEXT,
timestamp DATETIME NOT NULL,
is_withdrawal BOOLEAN NOT NULL DEFAULT 0,
FOREIGN KEY (peer_asn) REFERENCES asns(asn),
FOREIGN KEY (origin_asn) REFERENCES asns(asn)
);
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
);
-- Indexes for prefixes_v4 table
CREATE INDEX IF NOT EXISTS idx_prefixes_v4_prefix ON prefixes_v4(prefix);
-- Indexes for prefixes_v6 table
CREATE INDEX IF NOT EXISTS idx_prefixes_v6_prefix ON prefixes_v6(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_peer_asn ON announcements(peer_asn);
CREATE INDEX IF NOT EXISTS idx_announcements_origin_asn ON announcements(origin_asn);
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);
-- Indexes for asns table
CREATE INDEX IF NOT EXISTS idx_asns_asn ON asns(asn);
CREATE INDEX IF NOT EXISTS idx_asns_whois_updated_at ON asns(whois_updated_at);
-- 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);
-- IPv4 routing table maintained by PrefixHandler
CREATE TABLE IF NOT EXISTS live_routes_v4 (
id TEXT PRIMARY KEY,
prefix TEXT NOT NULL,
mask_length INTEGER NOT NULL, -- CIDR mask length (0-32)
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,
-- IPv4 range columns for fast lookups
ip_start INTEGER NOT NULL, -- Start of IPv4 range as 32-bit unsigned int
ip_end INTEGER NOT NULL, -- End of IPv4 range as 32-bit unsigned int
UNIQUE(prefix, origin_asn, peer_ip)
);
-- IPv6 routing table maintained by PrefixHandler
CREATE TABLE IF NOT EXISTS live_routes_v6 (
id TEXT PRIMARY KEY,
prefix TEXT NOT NULL,
mask_length INTEGER NOT NULL, -- CIDR mask length (0-128)
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,
-- Note: IPv6 doesn't use integer range columns
UNIQUE(prefix, origin_asn, peer_ip)
);
-- Indexes for live_routes_v4 table
CREATE INDEX IF NOT EXISTS idx_live_routes_v4_prefix ON live_routes_v4(prefix);
CREATE INDEX IF NOT EXISTS idx_live_routes_v4_mask_length ON live_routes_v4(mask_length);
CREATE INDEX IF NOT EXISTS idx_live_routes_v4_origin_asn ON live_routes_v4(origin_asn);
CREATE INDEX IF NOT EXISTS idx_live_routes_v4_last_updated ON live_routes_v4(last_updated);
-- Indexes for IPv4 range queries
CREATE INDEX IF NOT EXISTS idx_live_routes_v4_ip_range ON live_routes_v4(ip_start, ip_end);
-- Index to optimize prefix distribution queries
CREATE INDEX IF NOT EXISTS idx_live_routes_v4_mask_prefix ON live_routes_v4(mask_length, prefix);
-- Indexes for live_routes_v6 table
CREATE INDEX IF NOT EXISTS idx_live_routes_v6_prefix ON live_routes_v6(prefix);
CREATE INDEX IF NOT EXISTS idx_live_routes_v6_mask_length ON live_routes_v6(mask_length);
CREATE INDEX IF NOT EXISTS idx_live_routes_v6_origin_asn ON live_routes_v6(origin_asn);
CREATE INDEX IF NOT EXISTS idx_live_routes_v6_last_updated ON live_routes_v6(last_updated);
-- Index to optimize prefix distribution queries
CREATE INDEX IF NOT EXISTS idx_live_routes_v6_mask_prefix ON live_routes_v6(mask_length, prefix);