Files
CashumintsAPI/src/db/schema.sql
Michaël c2a7267459 Standardize all timestamps to UTC ISO-8601 format
- Update schema.sql defaults from datetime('now') to strftime('%Y-%m-%dT%H:%M:%fZ', 'now')
- Update schema-admin.sql with same UTC format
- Update AdminService.js inline table creation and query comparisons
- Update system.js time-based query comparisons
- Add documentation to time.js explaining UTC format convention
2025-12-21 19:10:07 -03:00

272 lines
9.8 KiB
SQL

-- Cashumints.space Database Schema
-- SQLite optimized for append-only historical data
-- Enable foreign keys
PRAGMA foreign_keys = ON;
-- ============================================
-- CORE TABLES
-- ============================================
-- Mints: Core identity table
CREATE TABLE IF NOT EXISTS mints (
mint_id TEXT PRIMARY KEY,
canonical_url TEXT NOT NULL,
name TEXT,
icon_url TEXT,
status TEXT NOT NULL DEFAULT 'unknown' CHECK (status IN ('unknown', 'online', 'degraded', 'offline', 'abandoned')),
offline_since TEXT,
last_success_at TEXT,
last_failure_at TEXT,
consecutive_failures INTEGER DEFAULT 0,
created_at TEXT NOT NULL DEFAULT (strftime('%Y-%m-%dT%H:%M:%fZ', 'now')),
updated_at TEXT NOT NULL DEFAULT (strftime('%Y-%m-%dT%H:%M:%fZ', 'now'))
);
CREATE INDEX IF NOT EXISTS idx_mints_status ON mints(status);
CREATE INDEX IF NOT EXISTS idx_mints_canonical_url ON mints(canonical_url);
-- Mint URLs: Multiple URLs per mint
CREATE TABLE IF NOT EXISTS mint_urls (
id INTEGER PRIMARY KEY AUTOINCREMENT,
mint_id TEXT NOT NULL REFERENCES mints(mint_id) ON DELETE CASCADE,
url TEXT NOT NULL UNIQUE,
url_normalized TEXT NOT NULL,
type TEXT NOT NULL DEFAULT 'clearnet' CHECK (type IN ('clearnet', 'tor', 'mirror')),
active INTEGER NOT NULL DEFAULT 1,
discovered_at TEXT NOT NULL DEFAULT (strftime('%Y-%m-%dT%H:%M:%fZ', 'now')),
last_seen_at TEXT NOT NULL DEFAULT (strftime('%Y-%m-%dT%H:%M:%fZ', 'now'))
);
CREATE INDEX IF NOT EXISTS idx_mint_urls_mint_id ON mint_urls(mint_id);
CREATE INDEX IF NOT EXISTS idx_mint_urls_url_normalized ON mint_urls(url_normalized);
CREATE INDEX IF NOT EXISTS idx_mint_urls_active ON mint_urls(active);
-- ============================================
-- PROBING & UPTIME
-- ============================================
-- Probes: Raw probe results (append-only)
CREATE TABLE IF NOT EXISTS probes (
id INTEGER PRIMARY KEY AUTOINCREMENT,
mint_id TEXT NOT NULL REFERENCES mints(mint_id) ON DELETE CASCADE,
url TEXT NOT NULL,
probed_at TEXT NOT NULL DEFAULT (strftime('%Y-%m-%dT%H:%M:%fZ', 'now')),
success INTEGER NOT NULL,
status_code INTEGER,
rtt_ms INTEGER,
error_type TEXT,
error_message TEXT
);
CREATE INDEX IF NOT EXISTS idx_probes_mint_id ON probes(mint_id);
CREATE INDEX IF NOT EXISTS idx_probes_probed_at ON probes(probed_at);
CREATE INDEX IF NOT EXISTS idx_probes_mint_probed ON probes(mint_id, probed_at);
-- Uptime Rollups: Aggregated uptime data
CREATE TABLE IF NOT EXISTS uptime_rollups (
id INTEGER PRIMARY KEY AUTOINCREMENT,
mint_id TEXT NOT NULL REFERENCES mints(mint_id) ON DELETE CASCADE,
window TEXT NOT NULL CHECK (window IN ('1h', '24h', '7d', '30d')),
period_start TEXT NOT NULL,
period_end TEXT NOT NULL,
uptime_pct REAL NOT NULL,
downtime_seconds INTEGER NOT NULL DEFAULT 0,
avg_rtt_ms REAL,
p95_rtt_ms REAL,
total_checks INTEGER NOT NULL DEFAULT 0,
ok_checks INTEGER NOT NULL DEFAULT 0,
incident_count INTEGER NOT NULL DEFAULT 0,
computed_at TEXT NOT NULL DEFAULT (strftime('%Y-%m-%dT%H:%M:%fZ', 'now')),
UNIQUE(mint_id, window, period_start)
);
CREATE INDEX IF NOT EXISTS idx_uptime_rollups_mint_window ON uptime_rollups(mint_id, window);
-- Incidents: Downtime events
CREATE TABLE IF NOT EXISTS incidents (
id INTEGER PRIMARY KEY AUTOINCREMENT,
mint_id TEXT NOT NULL REFERENCES mints(mint_id) ON DELETE CASCADE,
started_at TEXT NOT NULL,
resolved_at TEXT,
duration_seconds INTEGER,
severity TEXT NOT NULL DEFAULT 'minor' CHECK (severity IN ('minor', 'major', 'critical'))
);
CREATE INDEX IF NOT EXISTS idx_incidents_mint_id ON incidents(mint_id);
CREATE INDEX IF NOT EXISTS idx_incidents_started_at ON incidents(started_at);
-- ============================================
-- METADATA (NUT-06)
-- ============================================
-- Metadata Snapshots: Current state
CREATE TABLE IF NOT EXISTS metadata_snapshots (
mint_id TEXT PRIMARY KEY REFERENCES mints(mint_id) ON DELETE CASCADE,
name TEXT,
pubkey TEXT,
version TEXT,
description TEXT,
description_long TEXT,
contact TEXT,
motd TEXT,
icon_url TEXT,
urls TEXT, -- JSON array
tos_url TEXT,
nuts TEXT, -- JSON object
server_time TEXT,
raw_json TEXT, -- Full raw response
content_hash TEXT,
last_fetched_at TEXT NOT NULL DEFAULT (strftime('%Y-%m-%dT%H:%M:%fZ', 'now'))
);
-- Metadata History: All changes (append-only)
CREATE TABLE IF NOT EXISTS metadata_history (
id INTEGER PRIMARY KEY AUTOINCREMENT,
mint_id TEXT NOT NULL REFERENCES mints(mint_id) ON DELETE CASCADE,
fetched_at TEXT NOT NULL DEFAULT (strftime('%Y-%m-%dT%H:%M:%fZ', 'now')),
change_type TEXT NOT NULL CHECK (change_type IN ('initial', 'update', 'error')),
diff TEXT, -- JSON diff of changes
content_hash TEXT,
version TEXT,
raw_json TEXT
);
CREATE INDEX IF NOT EXISTS idx_metadata_history_mint_id ON metadata_history(mint_id);
CREATE INDEX IF NOT EXISTS idx_metadata_history_fetched_at ON metadata_history(fetched_at);
-- ============================================
-- NOSTR REVIEWS (NIP-87)
-- ============================================
-- Nostr Events: Raw events (append-only)
CREATE TABLE IF NOT EXISTS nostr_events (
id INTEGER PRIMARY KEY AUTOINCREMENT,
event_id TEXT NOT NULL UNIQUE,
kind INTEGER NOT NULL,
pubkey TEXT NOT NULL,
created_at INTEGER NOT NULL,
content TEXT,
tags TEXT, -- JSON array
sig TEXT NOT NULL,
raw_json TEXT NOT NULL,
ingested_at TEXT NOT NULL DEFAULT (strftime('%Y-%m-%dT%H:%M:%fZ', 'now'))
);
CREATE INDEX IF NOT EXISTS idx_nostr_events_event_id ON nostr_events(event_id);
CREATE INDEX IF NOT EXISTS idx_nostr_events_kind ON nostr_events(kind);
CREATE INDEX IF NOT EXISTS idx_nostr_events_pubkey ON nostr_events(pubkey);
CREATE INDEX IF NOT EXISTS idx_nostr_events_created_at ON nostr_events(created_at);
-- Reviews: Parsed review data linked to mints
CREATE TABLE IF NOT EXISTS reviews (
id INTEGER PRIMARY KEY AUTOINCREMENT,
event_id TEXT NOT NULL UNIQUE REFERENCES nostr_events(event_id),
mint_id TEXT REFERENCES mints(mint_id),
mint_url TEXT, -- Original URL from event
pubkey TEXT NOT NULL,
created_at INTEGER NOT NULL,
rating INTEGER CHECK (rating >= 1 AND rating <= 5),
content TEXT,
parsed_at TEXT NOT NULL DEFAULT (strftime('%Y-%m-%dT%H:%M:%fZ', 'now'))
);
CREATE INDEX IF NOT EXISTS idx_reviews_mint_id ON reviews(mint_id);
CREATE INDEX IF NOT EXISTS idx_reviews_pubkey ON reviews(pubkey);
CREATE INDEX IF NOT EXISTS idx_reviews_created_at ON reviews(created_at);
-- ============================================
-- TRUST SCORES
-- ============================================
CREATE TABLE IF NOT EXISTS trust_scores (
id INTEGER PRIMARY KEY AUTOINCREMENT,
mint_id TEXT NOT NULL REFERENCES mints(mint_id) ON DELETE CASCADE,
score_total INTEGER NOT NULL CHECK (score_total >= 0 AND score_total <= 100),
score_level TEXT NOT NULL CHECK (score_level IN ('unknown', 'low', 'medium', 'high', 'excellent')),
breakdown TEXT NOT NULL, -- JSON breakdown of score components
computed_at TEXT NOT NULL DEFAULT (strftime('%Y-%m-%dT%H:%M:%fZ', 'now')),
UNIQUE(mint_id, computed_at)
);
CREATE INDEX IF NOT EXISTS idx_trust_scores_mint_id ON trust_scores(mint_id);
-- Current trust score view
CREATE VIEW IF NOT EXISTS current_trust_scores AS
SELECT
t1.*
FROM trust_scores t1
INNER JOIN (
SELECT mint_id, MAX(computed_at) as max_computed_at
FROM trust_scores
GROUP BY mint_id
) t2 ON t1.mint_id = t2.mint_id AND t1.computed_at = t2.max_computed_at;
-- ============================================
-- PAGEVIEWS & ANALYTICS
-- ============================================
CREATE TABLE IF NOT EXISTS pageviews (
id INTEGER PRIMARY KEY AUTOINCREMENT,
mint_id TEXT NOT NULL REFERENCES mints(mint_id) ON DELETE CASCADE,
session_id TEXT NOT NULL,
viewed_at TEXT NOT NULL DEFAULT (strftime('%Y-%m-%dT%H:%M:%fZ', 'now')),
user_agent TEXT,
referer TEXT
);
CREATE INDEX IF NOT EXISTS idx_pageviews_mint_id ON pageviews(mint_id);
CREATE INDEX IF NOT EXISTS idx_pageviews_viewed_at ON pageviews(viewed_at);
CREATE INDEX IF NOT EXISTS idx_pageviews_session_id ON pageviews(session_id);
-- Pageview rollups
CREATE TABLE IF NOT EXISTS pageview_rollups (
id INTEGER PRIMARY KEY AUTOINCREMENT,
mint_id TEXT NOT NULL REFERENCES mints(mint_id) ON DELETE CASCADE,
window TEXT NOT NULL CHECK (window IN ('24h', '7d', '30d')),
period_start TEXT NOT NULL,
period_end TEXT NOT NULL,
view_count INTEGER NOT NULL DEFAULT 0,
unique_sessions INTEGER NOT NULL DEFAULT 0,
computed_at TEXT NOT NULL DEFAULT (strftime('%Y-%m-%dT%H:%M:%fZ', 'now')),
UNIQUE(mint_id, window, period_start)
);
CREATE INDEX IF NOT EXISTS idx_pageview_rollups_mint_window ON pageview_rollups(mint_id, window);
-- ============================================
-- JOB QUEUE
-- ============================================
CREATE TABLE IF NOT EXISTS jobs (
id INTEGER PRIMARY KEY AUTOINCREMENT,
type TEXT NOT NULL CHECK (type IN ('probe', 'metadata', 'rollup', 'trust_score', 'nostr_sync', 'cleanup')),
payload TEXT, -- JSON
status TEXT NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', 'running', 'completed', 'failed')),
priority INTEGER NOT NULL DEFAULT 0,
run_at TEXT NOT NULL DEFAULT (strftime('%Y-%m-%dT%H:%M:%fZ', 'now')),
started_at TEXT,
completed_at TEXT,
retries INTEGER NOT NULL DEFAULT 0,
max_retries INTEGER NOT NULL DEFAULT 3,
error_message TEXT,
created_at TEXT NOT NULL DEFAULT (strftime('%Y-%m-%dT%H:%M:%fZ', 'now'))
);
CREATE INDEX IF NOT EXISTS idx_jobs_status_run_at ON jobs(status, run_at);
CREATE INDEX IF NOT EXISTS idx_jobs_type ON jobs(type);
-- ============================================
-- SYSTEM STATS
-- ============================================
CREATE TABLE IF NOT EXISTS system_stats (
id INTEGER PRIMARY KEY AUTOINCREMENT,
stat_name TEXT NOT NULL,
stat_value TEXT NOT NULL,
recorded_at TEXT NOT NULL DEFAULT (strftime('%Y-%m-%dT%H:%M:%fZ', 'now'))
);
CREATE INDEX IF NOT EXISTS idx_system_stats_name ON system_stats(stat_name);