331 lines
12 KiB
C
331 lines
12 KiB
C
/* Embedded SQL Schema for C Nostr Relay
|
|
* Generated from db/schema.sql - Do not edit manually
|
|
* Schema Version: 7
|
|
*/
|
|
#ifndef SQL_SCHEMA_H
|
|
#define SQL_SCHEMA_H
|
|
|
|
/* Schema version constant */
|
|
#define EMBEDDED_SCHEMA_VERSION "7"
|
|
|
|
/* Embedded SQL schema as C string literal */
|
|
static const char* const EMBEDDED_SCHEMA_SQL =
|
|
"-- C Nostr Relay Database Schema\n\
|
|
-- SQLite schema for storing Nostr events with JSON tags support\n\
|
|
-- Configuration system using config table\n\
|
|
\n\
|
|
-- Schema version tracking\n\
|
|
PRAGMA user_version = 7;\n\
|
|
\n\
|
|
-- Enable foreign key support\n\
|
|
PRAGMA foreign_keys = ON;\n\
|
|
\n\
|
|
-- Optimize for performance\n\
|
|
PRAGMA journal_mode = WAL;\n\
|
|
PRAGMA synchronous = NORMAL;\n\
|
|
PRAGMA cache_size = 10000;\n\
|
|
\n\
|
|
-- Core events table with hybrid single-table design\n\
|
|
CREATE TABLE events (\n\
|
|
id TEXT PRIMARY KEY, -- Nostr event ID (hex string)\n\
|
|
pubkey TEXT NOT NULL, -- Public key of event author (hex string)\n\
|
|
created_at INTEGER NOT NULL, -- Event creation timestamp (Unix timestamp)\n\
|
|
kind INTEGER NOT NULL, -- Event kind (0-65535)\n\
|
|
event_type TEXT NOT NULL CHECK (event_type IN ('regular', 'replaceable', 'ephemeral', 'addressable')),\n\
|
|
content TEXT NOT NULL, -- Event content (text content only)\n\
|
|
sig TEXT NOT NULL, -- Event signature (hex string)\n\
|
|
tags JSON NOT NULL DEFAULT '[]', -- Event tags as JSON array\n\
|
|
first_seen INTEGER NOT NULL DEFAULT (strftime('%s', 'now')) -- When relay received event\n\
|
|
);\n\
|
|
\n\
|
|
-- Core performance indexes\n\
|
|
CREATE INDEX idx_events_pubkey ON events(pubkey);\n\
|
|
CREATE INDEX idx_events_kind ON events(kind);\n\
|
|
CREATE INDEX idx_events_created_at ON events(created_at DESC);\n\
|
|
CREATE INDEX idx_events_event_type ON events(event_type);\n\
|
|
\n\
|
|
-- Composite indexes for common query patterns\n\
|
|
CREATE INDEX idx_events_kind_created_at ON events(kind, created_at DESC);\n\
|
|
CREATE INDEX idx_events_pubkey_created_at ON events(pubkey, created_at DESC);\n\
|
|
CREATE INDEX idx_events_pubkey_kind ON events(pubkey, kind);\n\
|
|
\n\
|
|
-- Schema information table\n\
|
|
CREATE TABLE schema_info (\n\
|
|
key TEXT PRIMARY KEY,\n\
|
|
value TEXT NOT NULL,\n\
|
|
updated_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now'))\n\
|
|
);\n\
|
|
\n\
|
|
-- Insert schema metadata\n\
|
|
INSERT INTO schema_info (key, value) VALUES\n\
|
|
('version', '7'),\n\
|
|
('description', 'Hybrid Nostr relay schema with event-based and table-based configuration'),\n\
|
|
('created_at', strftime('%s', 'now'));\n\
|
|
\n\
|
|
-- Helper views for common queries\n\
|
|
CREATE VIEW recent_events AS\n\
|
|
SELECT id, pubkey, created_at, kind, event_type, content\n\
|
|
FROM events\n\
|
|
WHERE event_type != 'ephemeral'\n\
|
|
ORDER BY created_at DESC\n\
|
|
LIMIT 1000;\n\
|
|
\n\
|
|
CREATE VIEW event_stats AS\n\
|
|
SELECT \n\
|
|
event_type,\n\
|
|
COUNT(*) as count,\n\
|
|
AVG(length(content)) as avg_content_length,\n\
|
|
MIN(created_at) as earliest,\n\
|
|
MAX(created_at) as latest\n\
|
|
FROM events\n\
|
|
GROUP BY event_type;\n\
|
|
\n\
|
|
-- Configuration events view (kind 33334)\n\
|
|
CREATE VIEW configuration_events AS\n\
|
|
SELECT \n\
|
|
id,\n\
|
|
pubkey as admin_pubkey,\n\
|
|
created_at,\n\
|
|
content,\n\
|
|
tags,\n\
|
|
sig\n\
|
|
FROM events\n\
|
|
WHERE kind = 33334\n\
|
|
ORDER BY created_at DESC;\n\
|
|
\n\
|
|
-- Optimization: Trigger for automatic cleanup of ephemeral events older than 1 hour\n\
|
|
CREATE TRIGGER cleanup_ephemeral_events\n\
|
|
AFTER INSERT ON events\n\
|
|
WHEN NEW.event_type = 'ephemeral'\n\
|
|
BEGIN\n\
|
|
DELETE FROM events \n\
|
|
WHERE event_type = 'ephemeral' \n\
|
|
AND first_seen < (strftime('%s', 'now') - 3600);\n\
|
|
END;\n\
|
|
\n\
|
|
-- Replaceable event handling trigger\n\
|
|
CREATE TRIGGER handle_replaceable_events\n\
|
|
AFTER INSERT ON events\n\
|
|
WHEN NEW.event_type = 'replaceable'\n\
|
|
BEGIN\n\
|
|
DELETE FROM events \n\
|
|
WHERE pubkey = NEW.pubkey \n\
|
|
AND kind = NEW.kind \n\
|
|
AND event_type = 'replaceable'\n\
|
|
AND id != NEW.id;\n\
|
|
END;\n\
|
|
\n\
|
|
-- Addressable event handling trigger (for kind 33334 configuration events)\n\
|
|
CREATE TRIGGER handle_addressable_events\n\
|
|
AFTER INSERT ON events\n\
|
|
WHEN NEW.event_type = 'addressable'\n\
|
|
BEGIN\n\
|
|
-- For kind 33334 (configuration), replace previous config from same admin\n\
|
|
DELETE FROM events \n\
|
|
WHERE pubkey = NEW.pubkey \n\
|
|
AND kind = NEW.kind \n\
|
|
AND event_type = 'addressable'\n\
|
|
AND id != NEW.id;\n\
|
|
END;\n\
|
|
\n\
|
|
-- Relay Private Key Secure Storage\n\
|
|
-- Stores the relay's private key separately from public configuration\n\
|
|
CREATE TABLE relay_seckey (\n\
|
|
private_key_hex TEXT NOT NULL CHECK (length(private_key_hex) = 64),\n\
|
|
created_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now'))\n\
|
|
);\n\
|
|
\n\
|
|
-- Authentication Rules Table for NIP-42 and Policy Enforcement\n\
|
|
-- Used by request_validator.c for unified validation\n\
|
|
CREATE TABLE auth_rules (\n\
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,\n\
|
|
rule_type TEXT NOT NULL CHECK (rule_type IN ('whitelist', 'blacklist', 'rate_limit', 'auth_required')),\n\
|
|
pattern_type TEXT NOT NULL CHECK (pattern_type IN ('pubkey', 'kind', 'ip', 'global')),\n\
|
|
pattern_value TEXT,\n\
|
|
active INTEGER NOT NULL DEFAULT 1,\n\
|
|
created_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),\n\
|
|
updated_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now'))\n\
|
|
);\n\
|
|
\n\
|
|
-- Indexes for auth_rules performance\n\
|
|
CREATE INDEX idx_auth_rules_pattern ON auth_rules(pattern_type, pattern_value);\n\
|
|
CREATE INDEX idx_auth_rules_type ON auth_rules(rule_type);\n\
|
|
CREATE INDEX idx_auth_rules_active ON auth_rules(active);\n\
|
|
\n\
|
|
-- Configuration Table for Table-Based Config Management\n\
|
|
-- Hybrid system supporting both event-based and table-based configuration\n\
|
|
CREATE TABLE config (\n\
|
|
key TEXT PRIMARY KEY,\n\
|
|
value TEXT NOT NULL,\n\
|
|
data_type TEXT NOT NULL CHECK (data_type IN ('string', 'integer', 'boolean', 'json')),\n\
|
|
description TEXT,\n\
|
|
category TEXT DEFAULT 'general',\n\
|
|
requires_restart INTEGER DEFAULT 0,\n\
|
|
created_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),\n\
|
|
updated_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now'))\n\
|
|
);\n\
|
|
\n\
|
|
-- Indexes for config table performance\n\
|
|
CREATE INDEX idx_config_category ON config(category);\n\
|
|
CREATE INDEX idx_config_restart ON config(requires_restart);\n\
|
|
CREATE INDEX idx_config_updated ON config(updated_at DESC);\n\
|
|
\n\
|
|
-- Trigger to update config timestamp on changes\n\
|
|
CREATE TRIGGER update_config_timestamp\n\
|
|
AFTER UPDATE ON config\n\
|
|
FOR EACH ROW\n\
|
|
BEGIN\n\
|
|
UPDATE config SET updated_at = strftime('%s', 'now') WHERE key = NEW.key;\n\
|
|
END;\n\
|
|
\n\
|
|
-- Persistent Subscriptions Logging Tables (Phase 2)\n\
|
|
-- Optional database logging for subscription analytics and debugging\n\
|
|
\n\
|
|
-- Subscription events log\n\
|
|
CREATE TABLE subscription_events (\n\
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,\n\
|
|
subscription_id TEXT NOT NULL, -- Subscription ID from client\n\
|
|
client_ip TEXT NOT NULL, -- Client IP address\n\
|
|
event_type TEXT NOT NULL CHECK (event_type IN ('created', 'closed', 'expired', 'disconnected')),\n\
|
|
filter_json TEXT, -- JSON representation of filters (for created events)\n\
|
|
events_sent INTEGER DEFAULT 0, -- Number of events sent to this subscription\n\
|
|
created_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),\n\
|
|
ended_at INTEGER, -- When subscription ended (for closed/expired/disconnected)\n\
|
|
duration INTEGER -- Computed: ended_at - created_at\n\
|
|
);\n\
|
|
\n\
|
|
-- Subscription metrics summary\n\
|
|
CREATE TABLE subscription_metrics (\n\
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,\n\
|
|
date TEXT NOT NULL, -- Date (YYYY-MM-DD)\n\
|
|
total_created INTEGER DEFAULT 0, -- Total subscriptions created\n\
|
|
total_closed INTEGER DEFAULT 0, -- Total subscriptions closed\n\
|
|
total_events_broadcast INTEGER DEFAULT 0, -- Total events broadcast\n\
|
|
avg_duration REAL DEFAULT 0, -- Average subscription duration\n\
|
|
peak_concurrent INTEGER DEFAULT 0, -- Peak concurrent subscriptions\n\
|
|
updated_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),\n\
|
|
UNIQUE(date)\n\
|
|
);\n\
|
|
\n\
|
|
-- Event broadcasting log (optional, for detailed analytics)\n\
|
|
CREATE TABLE event_broadcasts (\n\
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,\n\
|
|
event_id TEXT NOT NULL, -- Event ID that was broadcast\n\
|
|
subscription_id TEXT NOT NULL, -- Subscription that received it\n\
|
|
client_ip TEXT NOT NULL, -- Client IP\n\
|
|
broadcast_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now')),\n\
|
|
FOREIGN KEY (event_id) REFERENCES events(id)\n\
|
|
);\n\
|
|
\n\
|
|
-- Indexes for subscription logging performance\n\
|
|
CREATE INDEX idx_subscription_events_id ON subscription_events(subscription_id);\n\
|
|
CREATE INDEX idx_subscription_events_type ON subscription_events(event_type);\n\
|
|
CREATE INDEX idx_subscription_events_created ON subscription_events(created_at DESC);\n\
|
|
CREATE INDEX idx_subscription_events_client ON subscription_events(client_ip);\n\
|
|
\n\
|
|
CREATE INDEX idx_subscription_metrics_date ON subscription_metrics(date DESC);\n\
|
|
\n\
|
|
CREATE INDEX idx_event_broadcasts_event ON event_broadcasts(event_id);\n\
|
|
CREATE INDEX idx_event_broadcasts_sub ON event_broadcasts(subscription_id);\n\
|
|
CREATE INDEX idx_event_broadcasts_time ON event_broadcasts(broadcast_at DESC);\n\
|
|
\n\
|
|
-- Trigger to update subscription duration when ended\n\
|
|
CREATE TRIGGER update_subscription_duration\n\
|
|
AFTER UPDATE OF ended_at ON subscription_events\n\
|
|
WHEN NEW.ended_at IS NOT NULL AND OLD.ended_at IS NULL\n\
|
|
BEGIN\n\
|
|
UPDATE subscription_events\n\
|
|
SET duration = NEW.ended_at - NEW.created_at\n\
|
|
WHERE id = NEW.id;\n\
|
|
END;\n\
|
|
\n\
|
|
-- View for subscription analytics\n\
|
|
CREATE VIEW subscription_analytics AS\n\
|
|
SELECT\n\
|
|
date(created_at, 'unixepoch') as date,\n\
|
|
COUNT(*) as subscriptions_created,\n\
|
|
COUNT(CASE WHEN ended_at IS NOT NULL THEN 1 END) as subscriptions_ended,\n\
|
|
AVG(CASE WHEN duration IS NOT NULL THEN duration END) as avg_duration_seconds,\n\
|
|
MAX(events_sent) as max_events_sent,\n\
|
|
AVG(events_sent) as avg_events_sent,\n\
|
|
COUNT(DISTINCT client_ip) as unique_clients\n\
|
|
FROM subscription_events\n\
|
|
GROUP BY date(created_at, 'unixepoch')\n\
|
|
ORDER BY date DESC;\n\
|
|
\n\
|
|
-- View for current active subscriptions (from log perspective)\n\
|
|
CREATE VIEW active_subscriptions_log AS\n\
|
|
SELECT\n\
|
|
subscription_id,\n\
|
|
client_ip,\n\
|
|
filter_json,\n\
|
|
events_sent,\n\
|
|
created_at,\n\
|
|
(strftime('%s', 'now') - created_at) as duration_seconds\n\
|
|
FROM subscription_events\n\
|
|
WHERE event_type = 'created'\n\
|
|
AND subscription_id NOT IN (\n\
|
|
SELECT subscription_id FROM subscription_events\n\
|
|
WHERE event_type IN ('closed', 'expired', 'disconnected')\n\
|
|
);\n\
|
|
\n\
|
|
-- Database Statistics Views for Admin API\n\
|
|
-- Event kinds distribution view\n\
|
|
CREATE VIEW event_kinds_view AS\n\
|
|
SELECT\n\
|
|
kind,\n\
|
|
COUNT(*) as count,\n\
|
|
ROUND(COUNT(*) * 100.0 / (SELECT COUNT(*) FROM events), 2) as percentage\n\
|
|
FROM events\n\
|
|
GROUP BY kind\n\
|
|
ORDER BY count DESC;\n\
|
|
\n\
|
|
-- Top pubkeys by event count view\n\
|
|
CREATE VIEW top_pubkeys_view AS\n\
|
|
SELECT\n\
|
|
pubkey,\n\
|
|
COUNT(*) as event_count,\n\
|
|
ROUND(COUNT(*) * 100.0 / (SELECT COUNT(*) FROM events), 2) as percentage\n\
|
|
FROM events\n\
|
|
GROUP BY pubkey\n\
|
|
ORDER BY event_count DESC\n\
|
|
LIMIT 10;\n\
|
|
\n\
|
|
-- Time-based statistics view\n\
|
|
CREATE VIEW time_stats_view AS\n\
|
|
SELECT\n\
|
|
'total' as period,\n\
|
|
COUNT(*) as total_events,\n\
|
|
COUNT(DISTINCT pubkey) as unique_pubkeys,\n\
|
|
MIN(created_at) as oldest_event,\n\
|
|
MAX(created_at) as newest_event\n\
|
|
FROM events\n\
|
|
UNION ALL\n\
|
|
SELECT\n\
|
|
'24h' as period,\n\
|
|
COUNT(*) as total_events,\n\
|
|
COUNT(DISTINCT pubkey) as unique_pubkeys,\n\
|
|
MIN(created_at) as oldest_event,\n\
|
|
MAX(created_at) as newest_event\n\
|
|
FROM events\n\
|
|
WHERE created_at >= (strftime('%s', 'now') - 86400)\n\
|
|
UNION ALL\n\
|
|
SELECT\n\
|
|
'7d' as period,\n\
|
|
COUNT(*) as total_events,\n\
|
|
COUNT(DISTINCT pubkey) as unique_pubkeys,\n\
|
|
MIN(created_at) as oldest_event,\n\
|
|
MAX(created_at) as newest_event\n\
|
|
FROM events\n\
|
|
WHERE created_at >= (strftime('%s', 'now') - 604800)\n\
|
|
UNION ALL\n\
|
|
SELECT\n\
|
|
'30d' as period,\n\
|
|
COUNT(*) as total_events,\n\
|
|
COUNT(DISTINCT pubkey) as unique_pubkeys,\n\
|
|
MIN(created_at) as oldest_event,\n\
|
|
MAX(created_at) as newest_event\n\
|
|
FROM events\n\
|
|
WHERE created_at >= (strftime('%s', 'now') - 2592000);";
|
|
|
|
#endif /* SQL_SCHEMA_H */ |