277 lines
9.3 KiB
Python
277 lines
9.3 KiB
Python
"""SQLite storage and schema setup for the registry API."""
|
|
|
|
from __future__ import annotations
|
|
|
|
import os
|
|
import sqlite3
|
|
from pathlib import Path
|
|
from typing import Iterable
|
|
|
|
|
|
SCHEMA_SQL = """
|
|
CREATE TABLE IF NOT EXISTS publishers (
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
email TEXT UNIQUE NOT NULL,
|
|
password_hash TEXT NOT NULL,
|
|
slug TEXT UNIQUE NOT NULL,
|
|
display_name TEXT NOT NULL,
|
|
bio TEXT,
|
|
website TEXT,
|
|
verified BOOLEAN DEFAULT FALSE,
|
|
locked_until TIMESTAMP,
|
|
failed_login_attempts INTEGER DEFAULT 0,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS api_tokens (
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
publisher_id INTEGER NOT NULL REFERENCES publishers(id),
|
|
token_hash TEXT NOT NULL,
|
|
name TEXT NOT NULL,
|
|
last_used_at TIMESTAMP,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
revoked_at TIMESTAMP
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS tools (
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
owner TEXT NOT NULL,
|
|
name TEXT NOT NULL,
|
|
version TEXT NOT NULL,
|
|
description TEXT,
|
|
category TEXT,
|
|
tags TEXT,
|
|
config_yaml TEXT NOT NULL,
|
|
readme TEXT,
|
|
publisher_id INTEGER NOT NULL REFERENCES publishers(id),
|
|
deprecated BOOLEAN DEFAULT FALSE,
|
|
deprecated_message TEXT,
|
|
replacement TEXT,
|
|
downloads INTEGER DEFAULT 0,
|
|
scrutiny_status TEXT DEFAULT 'pending',
|
|
scrutiny_report TEXT,
|
|
published_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
UNIQUE(owner, name, version)
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS download_stats (
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
tool_id INTEGER NOT NULL REFERENCES tools(id),
|
|
client_id TEXT NOT NULL,
|
|
downloaded_at DATE NOT NULL,
|
|
UNIQUE(tool_id, client_id, downloaded_at)
|
|
);
|
|
|
|
CREATE VIRTUAL TABLE IF NOT EXISTS tools_fts USING fts5(
|
|
name, description, tags, readme,
|
|
content='tools',
|
|
content_rowid='id'
|
|
);
|
|
|
|
CREATE TRIGGER IF NOT EXISTS tools_ai AFTER INSERT ON tools BEGIN
|
|
INSERT INTO tools_fts(rowid, name, description, tags, readme)
|
|
VALUES (new.id, new.name, new.description, new.tags, new.readme);
|
|
END;
|
|
|
|
CREATE TRIGGER IF NOT EXISTS tools_ad AFTER DELETE ON tools BEGIN
|
|
INSERT INTO tools_fts(tools_fts, rowid, name, description, tags, readme)
|
|
VALUES ('delete', old.id, old.name, old.description, old.tags, old.readme);
|
|
END;
|
|
|
|
CREATE TRIGGER IF NOT EXISTS tools_au AFTER UPDATE ON tools BEGIN
|
|
INSERT INTO tools_fts(tools_fts, rowid, name, description, tags, readme)
|
|
VALUES ('delete', old.id, old.name, old.description, old.tags, old.readme);
|
|
INSERT INTO tools_fts(rowid, name, description, tags, readme)
|
|
VALUES (new.id, new.name, new.description, new.tags, new.readme);
|
|
END;
|
|
|
|
CREATE TABLE IF NOT EXISTS pending_prs (
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
publisher_id INTEGER NOT NULL REFERENCES publishers(id),
|
|
owner TEXT NOT NULL,
|
|
name TEXT NOT NULL,
|
|
version TEXT NOT NULL,
|
|
pr_number INTEGER NOT NULL,
|
|
pr_url TEXT NOT NULL,
|
|
status TEXT NOT NULL DEFAULT 'pending',
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
UNIQUE(owner, name, version)
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS webhook_log (
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
delivery_id TEXT UNIQUE NOT NULL,
|
|
event_type TEXT NOT NULL,
|
|
processed_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS web_sessions (
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
session_id TEXT UNIQUE NOT NULL,
|
|
publisher_id INTEGER REFERENCES publishers(id),
|
|
data TEXT,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
expires_at TIMESTAMP NOT NULL
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_tools_owner_name ON tools(owner, name);
|
|
CREATE INDEX IF NOT EXISTS idx_tools_category ON tools(category);
|
|
CREATE INDEX IF NOT EXISTS idx_tools_published_at ON tools(published_at DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_tools_downloads ON tools(downloads DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_tools_owner_name_version ON tools(owner, name, version);
|
|
CREATE INDEX IF NOT EXISTS idx_tools_sort_stable ON tools(downloads DESC, published_at DESC, id DESC);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_publishers_slug ON publishers(slug);
|
|
CREATE INDEX IF NOT EXISTS idx_publishers_email ON publishers(email);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_api_tokens_hash ON api_tokens(token_hash);
|
|
CREATE INDEX IF NOT EXISTS idx_api_tokens_publisher ON api_tokens(publisher_id);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_web_sessions_id ON web_sessions(session_id);
|
|
CREATE INDEX IF NOT EXISTS idx_web_sessions_expires ON web_sessions(expires_at);
|
|
|
|
-- Web UI tables (Phase 7)
|
|
|
|
CREATE TABLE IF NOT EXISTS announcements (
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
title TEXT NOT NULL,
|
|
body TEXT NOT NULL,
|
|
published BOOLEAN DEFAULT FALSE,
|
|
published_at TIMESTAMP,
|
|
created_by INTEGER REFERENCES publishers(id),
|
|
updated_by INTEGER REFERENCES publishers(id),
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS featured_tools (
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
tool_id INTEGER NOT NULL REFERENCES tools(id),
|
|
placement TEXT NOT NULL DEFAULT 'homepage',
|
|
priority INTEGER DEFAULT 0,
|
|
start_at TIMESTAMP,
|
|
end_at TIMESTAMP,
|
|
status TEXT DEFAULT 'active',
|
|
created_by INTEGER REFERENCES publishers(id),
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS featured_contributors (
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
publisher_id INTEGER NOT NULL REFERENCES publishers(id),
|
|
bio_override TEXT,
|
|
placement TEXT NOT NULL DEFAULT 'homepage',
|
|
start_at TIMESTAMP,
|
|
end_at TIMESTAMP,
|
|
status TEXT DEFAULT 'active',
|
|
created_by INTEGER REFERENCES publishers(id),
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS reports (
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
tool_id INTEGER NOT NULL REFERENCES tools(id),
|
|
reporter_id INTEGER REFERENCES publishers(id),
|
|
reporter_ip TEXT,
|
|
reason TEXT NOT NULL,
|
|
details TEXT,
|
|
status TEXT DEFAULT 'pending',
|
|
resolved_by INTEGER REFERENCES publishers(id),
|
|
resolved_at TIMESTAMP,
|
|
resolution_note TEXT,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS consents (
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
client_id TEXT,
|
|
publisher_id INTEGER REFERENCES publishers(id),
|
|
analytics_consent BOOLEAN DEFAULT FALSE,
|
|
ads_consent BOOLEAN DEFAULT FALSE,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
UNIQUE(client_id),
|
|
UNIQUE(publisher_id)
|
|
);
|
|
|
|
CREATE TABLE IF NOT EXISTS content_pages (
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
slug TEXT UNIQUE NOT NULL,
|
|
title TEXT NOT NULL,
|
|
description TEXT,
|
|
content_type TEXT NOT NULL DEFAULT 'doc',
|
|
body TEXT,
|
|
published BOOLEAN DEFAULT FALSE,
|
|
published_at TIMESTAMP,
|
|
created_by INTEGER REFERENCES publishers(id),
|
|
updated_by INTEGER REFERENCES publishers(id),
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_announcements_published ON announcements(published, published_at DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_featured_tools_placement ON featured_tools(placement, status, priority DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_featured_contributors_placement ON featured_contributors(placement, status);
|
|
CREATE INDEX IF NOT EXISTS idx_reports_status ON reports(status, created_at DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_content_pages_type ON content_pages(content_type, published);
|
|
|
|
CREATE TABLE IF NOT EXISTS pageviews (
|
|
id INTEGER PRIMARY KEY AUTOINCREMENT,
|
|
path TEXT NOT NULL,
|
|
referrer TEXT,
|
|
user_agent TEXT,
|
|
ip_hash TEXT,
|
|
viewed_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
CREATE INDEX IF NOT EXISTS idx_pageviews_path ON pageviews(path, viewed_at DESC);
|
|
CREATE INDEX IF NOT EXISTS idx_pageviews_date ON pageviews(date(viewed_at), path);
|
|
"""
|
|
|
|
|
|
def get_db_path() -> Path:
|
|
default_path = Path.home() / ".smarttools" / "registry" / "registry.db"
|
|
return Path(os.environ.get("SMARTTOOLS_REGISTRY_DB", default_path))
|
|
|
|
|
|
def ensure_db_directory(path: Path) -> None:
|
|
path.parent.mkdir(parents=True, exist_ok=True)
|
|
|
|
|
|
def connect_db(path: Path | None = None) -> sqlite3.Connection:
|
|
db_path = path or get_db_path()
|
|
ensure_db_directory(db_path)
|
|
conn = sqlite3.connect(db_path)
|
|
conn.row_factory = sqlite3.Row
|
|
# WAL mode provides better concurrency but may not work on all filesystems
|
|
# (e.g., some FUSE filesystems like mergerfs). Fall back gracefully.
|
|
try:
|
|
conn.execute("PRAGMA journal_mode=WAL;")
|
|
except sqlite3.OperationalError:
|
|
# Fall back to DELETE journal mode which works everywhere
|
|
conn.execute("PRAGMA journal_mode=DELETE;")
|
|
conn.execute("PRAGMA foreign_keys=ON;")
|
|
return conn
|
|
|
|
|
|
def init_db(conn: sqlite3.Connection) -> None:
|
|
conn.executescript(SCHEMA_SQL)
|
|
conn.commit()
|
|
|
|
|
|
def query_one(conn: sqlite3.Connection, sql: str, params: Iterable | None = None):
|
|
cur = conn.execute(sql, params or [])
|
|
return cur.fetchone()
|
|
|
|
|
|
def query_all(conn: sqlite3.Connection, sql: str, params: Iterable | None = None):
|
|
cur = conn.execute(sql, params or [])
|
|
return cur.fetchall()
|
|
|
|
|
|
def execute(conn: sqlite3.Connection, sql: str, params: Iterable | None = None) -> None:
|
|
conn.execute(sql, params or [])
|
|
conn.commit()
|