Basic relay functionality completed
This commit is contained in:
116
db/schema.sql
116
db/schema.sql
@@ -1,66 +1,90 @@
|
||||
-- C Nostr Relay Database Schema
|
||||
-- Simplified schema with just event and tag tables
|
||||
-- SQLite database for storing Nostr events
|
||||
-- SQLite schema for storing Nostr events with JSON tags support
|
||||
|
||||
-- ============================================================================
|
||||
-- DATABASE SETTINGS
|
||||
-- ============================================================================
|
||||
-- Schema version tracking
|
||||
PRAGMA user_version = 2;
|
||||
|
||||
PRAGMA encoding = "UTF-8";
|
||||
PRAGMA journal_mode = WAL;
|
||||
PRAGMA auto_vacuum = FULL;
|
||||
PRAGMA synchronous = NORMAL;
|
||||
-- Enable foreign key support
|
||||
PRAGMA foreign_keys = ON;
|
||||
|
||||
-- ============================================================================
|
||||
-- EVENT TABLE
|
||||
-- ============================================================================
|
||||
-- Optimize for performance
|
||||
PRAGMA journal_mode = WAL;
|
||||
PRAGMA synchronous = NORMAL;
|
||||
PRAGMA cache_size = 10000;
|
||||
|
||||
-- Main event table - stores all Nostr events
|
||||
CREATE TABLE IF NOT EXISTS event (
|
||||
-- Core events table with hybrid single-table design
|
||||
CREATE TABLE events (
|
||||
id TEXT PRIMARY KEY, -- Nostr event ID (hex string)
|
||||
pubkey TEXT NOT NULL, -- Public key of event author (hex string)
|
||||
created_at INTEGER NOT NULL, -- Event creation timestamp (Unix timestamp)
|
||||
kind INTEGER NOT NULL, -- Event kind (0-65535)
|
||||
event_type TEXT NOT NULL CHECK (event_type IN ('regular', 'replaceable', 'ephemeral', 'addressable')),
|
||||
content TEXT NOT NULL, -- Event content (text content only)
|
||||
sig TEXT NOT NULL -- Event signature (hex string)
|
||||
sig TEXT NOT NULL, -- Event signature (hex string)
|
||||
tags JSON NOT NULL DEFAULT '[]', -- Event tags as JSON array
|
||||
first_seen INTEGER NOT NULL DEFAULT (strftime('%s', 'now')) -- When relay received event
|
||||
);
|
||||
|
||||
-- Event indexes for performance
|
||||
CREATE INDEX IF NOT EXISTS event_pubkey_index ON event(pubkey);
|
||||
CREATE INDEX IF NOT EXISTS event_created_at_index ON event(created_at);
|
||||
CREATE INDEX IF NOT EXISTS event_kind_index ON event(kind);
|
||||
CREATE INDEX IF NOT EXISTS event_pubkey_created_at_index ON event(pubkey, created_at);
|
||||
CREATE INDEX IF NOT EXISTS event_kind_created_at_index ON event(kind, created_at);
|
||||
-- Core performance indexes
|
||||
CREATE INDEX idx_events_pubkey ON events(pubkey);
|
||||
CREATE INDEX idx_events_kind ON events(kind);
|
||||
CREATE INDEX idx_events_created_at ON events(created_at DESC);
|
||||
CREATE INDEX idx_events_event_type ON events(event_type);
|
||||
|
||||
-- ============================================================================
|
||||
-- TAG TABLE
|
||||
-- ============================================================================
|
||||
-- Composite indexes for common query patterns
|
||||
CREATE INDEX idx_events_kind_created_at ON events(kind, created_at DESC);
|
||||
CREATE INDEX idx_events_pubkey_created_at ON events(pubkey, created_at DESC);
|
||||
CREATE INDEX idx_events_pubkey_kind ON events(pubkey, kind);
|
||||
|
||||
-- Tag table for storing event tags
|
||||
CREATE TABLE IF NOT EXISTS tag (
|
||||
id TEXT NOT NULL, -- Nostr event ID (references event.id)
|
||||
name TEXT NOT NULL, -- Tag name (e.g., "e", "p", "d")
|
||||
value TEXT NOT NULL, -- Tag value
|
||||
parameters TEXT, -- Additional tag parameters (JSON string)
|
||||
FOREIGN KEY(id) REFERENCES event(id) ON UPDATE CASCADE ON DELETE CASCADE
|
||||
-- Schema information table
|
||||
CREATE TABLE schema_info (
|
||||
key TEXT PRIMARY KEY,
|
||||
value TEXT NOT NULL,
|
||||
updated_at INTEGER NOT NULL DEFAULT (strftime('%s', 'now'))
|
||||
);
|
||||
|
||||
-- Tag indexes for performance
|
||||
CREATE INDEX IF NOT EXISTS tag_id_index ON tag(id);
|
||||
CREATE INDEX IF NOT EXISTS tag_name_index ON tag(name);
|
||||
CREATE INDEX IF NOT EXISTS tag_name_value_index ON tag(name, value);
|
||||
CREATE INDEX IF NOT EXISTS tag_id_name_index ON tag(id, name);
|
||||
-- Insert schema metadata
|
||||
INSERT INTO schema_info (key, value) VALUES
|
||||
('version', '2'),
|
||||
('description', 'Hybrid single-table Nostr relay schema with JSON tags'),
|
||||
('created_at', strftime('%s', 'now'));
|
||||
|
||||
-- ============================================================================
|
||||
-- PERFORMANCE OPTIMIZATIONS
|
||||
-- ============================================================================
|
||||
-- Helper views for common queries
|
||||
CREATE VIEW recent_events AS
|
||||
SELECT id, pubkey, created_at, kind, event_type, content
|
||||
FROM events
|
||||
WHERE event_type != 'ephemeral'
|
||||
ORDER BY created_at DESC
|
||||
LIMIT 1000;
|
||||
|
||||
-- Enable query planner optimizations
|
||||
PRAGMA optimize;
|
||||
CREATE VIEW event_stats AS
|
||||
SELECT
|
||||
event_type,
|
||||
COUNT(*) as count,
|
||||
AVG(length(content)) as avg_content_length,
|
||||
MIN(created_at) as earliest,
|
||||
MAX(created_at) as latest
|
||||
FROM events
|
||||
GROUP BY event_type;
|
||||
|
||||
-- Set recommended pragmas for performance
|
||||
PRAGMA main.synchronous = NORMAL;
|
||||
PRAGMA foreign_keys = ON;
|
||||
PRAGMA temp_store = 2; -- use memory for temp tables
|
||||
PRAGMA main.cache_size = 10000; -- 40MB cache per connection
|
||||
-- Optimization: Trigger for automatic cleanup of ephemeral events older than 1 hour
|
||||
CREATE TRIGGER cleanup_ephemeral_events
|
||||
AFTER INSERT ON events
|
||||
WHEN NEW.event_type = 'ephemeral'
|
||||
BEGIN
|
||||
DELETE FROM events
|
||||
WHERE event_type = 'ephemeral'
|
||||
AND first_seen < (strftime('%s', 'now') - 3600);
|
||||
END;
|
||||
|
||||
-- Replaceable event handling trigger
|
||||
CREATE TRIGGER handle_replaceable_events
|
||||
AFTER INSERT ON events
|
||||
WHEN NEW.event_type = 'replaceable'
|
||||
BEGIN
|
||||
DELETE FROM events
|
||||
WHERE pubkey = NEW.pubkey
|
||||
AND kind = NEW.kind
|
||||
AND event_type = 'replaceable'
|
||||
AND id != NEW.id;
|
||||
END;
|
||||
Reference in New Issue
Block a user