Files
motr-enclave/db/schema.sql

265 lines
14 KiB
SQL

-- =============================================================================
-- NEBULA KEY ENCLAVE SCHEMA
-- Encrypted SQLite database for sensitive wallet data
-- =============================================================================
PRAGMA foreign_keys = ON;
-- =============================================================================
-- IDENTITY
-- =============================================================================
-- DID Documents: Local cache of Sonr DID state
CREATE TABLE IF NOT EXISTS did_documents (
id INTEGER PRIMARY KEY,
did TEXT NOT NULL UNIQUE, -- did:sonr:abc123...
controller TEXT NOT NULL, -- Controller DID
document TEXT NOT NULL, -- Full DID Document (JSON)
sequence INTEGER NOT NULL DEFAULT 0, -- On-chain sequence number
last_synced TEXT NOT NULL DEFAULT (datetime('now')),
created_at TEXT NOT NULL DEFAULT (datetime('now')),
updated_at TEXT NOT NULL DEFAULT (datetime('now'))
);
CREATE INDEX idx_did_documents_did ON did_documents(did);
-- Verification Methods: Keys associated with DID
CREATE TABLE IF NOT EXISTS verification_methods (
id INTEGER PRIMARY KEY,
did_id INTEGER NOT NULL REFERENCES did_documents(id) ON DELETE CASCADE,
method_id TEXT NOT NULL, -- did:sonr:abc#key-1
method_type TEXT NOT NULL, -- Ed25519VerificationKey2020, etc.
controller TEXT NOT NULL,
public_key TEXT NOT NULL, -- Base64 encoded public key
purpose TEXT NOT NULL DEFAULT 'authentication', -- authentication, assertion, keyAgreement, capabilityInvocation, capabilityDelegation
created_at TEXT NOT NULL DEFAULT (datetime('now')),
UNIQUE(did_id, method_id)
);
CREATE INDEX idx_verification_methods_did_id ON verification_methods(did_id);
-- =============================================================================
-- WEBAUTHN CREDENTIALS
-- =============================================================================
-- Credentials: WebAuthn credential storage
CREATE TABLE IF NOT EXISTS credentials (
id INTEGER PRIMARY KEY,
did_id INTEGER NOT NULL REFERENCES did_documents(id) ON DELETE CASCADE,
credential_id TEXT NOT NULL UNIQUE, -- WebAuthn credential ID (base64)
public_key TEXT NOT NULL, -- COSE public key (base64)
public_key_alg INTEGER NOT NULL, -- COSE algorithm (-7 = ES256, -257 = RS256)
aaguid TEXT, -- Authenticator AAGUID
sign_count INTEGER NOT NULL DEFAULT 0, -- Signature counter
transports TEXT DEFAULT '[]', -- JSON array: ["internal", "usb", "nfc", "ble"]
device_name TEXT NOT NULL, -- User-assigned name
device_type TEXT NOT NULL DEFAULT 'platform', -- platform, cross-platform
authenticator TEXT, -- Touch ID, Face ID, Windows Hello, YubiKey
is_discoverable INTEGER NOT NULL DEFAULT 1, -- Resident key / passkey
backed_up INTEGER NOT NULL DEFAULT 0, -- Credential backed up (BE flag)
created_at TEXT NOT NULL DEFAULT (datetime('now')),
last_used TEXT NOT NULL DEFAULT (datetime('now'))
);
CREATE INDEX idx_credentials_did_id ON credentials(did_id);
CREATE INDEX idx_credentials_credential_id ON credentials(credential_id);
-- =============================================================================
-- MPC KEY SHARES
-- =============================================================================
-- Key Shares: MPC/TSS key share storage
CREATE TABLE IF NOT EXISTS key_shares (
id INTEGER PRIMARY KEY,
did_id INTEGER NOT NULL REFERENCES did_documents(id) ON DELETE CASCADE,
share_id TEXT NOT NULL UNIQUE, -- Unique identifier for this share
key_id TEXT NOT NULL, -- Identifier for the full key (shared across parties)
party_index INTEGER NOT NULL, -- This party's index (1, 2, 3...)
threshold INTEGER NOT NULL, -- Minimum shares needed to sign
total_parties INTEGER NOT NULL, -- Total number of parties
curve TEXT NOT NULL DEFAULT 'secp256k1', -- secp256k1, ed25519
share_data TEXT NOT NULL, -- Encrypted key share (base64)
public_key TEXT NOT NULL, -- Full public key (base64)
chain_code TEXT, -- BIP32 chain code for derivation
derivation_path TEXT, -- BIP44 path: m/44'/60'/0'/0
status TEXT NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'rotating', 'archived')),
created_at TEXT NOT NULL DEFAULT (datetime('now')),
rotated_at TEXT,
UNIQUE(did_id, key_id, party_index)
);
CREATE INDEX idx_key_shares_did_id ON key_shares(did_id);
CREATE INDEX idx_key_shares_key_id ON key_shares(key_id);
-- Derived Accounts: Wallet accounts derived from key shares
CREATE TABLE IF NOT EXISTS accounts (
id INTEGER PRIMARY KEY,
did_id INTEGER NOT NULL REFERENCES did_documents(id) ON DELETE CASCADE,
key_share_id INTEGER NOT NULL REFERENCES key_shares(id) ON DELETE CASCADE,
address TEXT NOT NULL, -- Derived address
chain_id TEXT NOT NULL, -- sonr-mainnet-1, ethereum, etc.
coin_type INTEGER NOT NULL, -- BIP44 coin type (118=cosmos, 60=eth)
account_index INTEGER NOT NULL DEFAULT 0, -- BIP44 account index
address_index INTEGER NOT NULL DEFAULT 0, -- BIP44 address index
label TEXT DEFAULT '', -- User-assigned label
is_default INTEGER NOT NULL DEFAULT 0,
created_at TEXT NOT NULL DEFAULT (datetime('now')),
UNIQUE(key_share_id, chain_id, account_index, address_index)
);
CREATE INDEX idx_accounts_did_id ON accounts(did_id);
CREATE INDEX idx_accounts_address ON accounts(address);
CREATE INDEX idx_accounts_chain_id ON accounts(chain_id);
-- =============================================================================
-- UCAN AUTHORIZATION
-- =============================================================================
-- UCAN Tokens: Capability authorization tokens
CREATE TABLE IF NOT EXISTS ucan_tokens (
id INTEGER PRIMARY KEY,
did_id INTEGER NOT NULL REFERENCES did_documents(id) ON DELETE CASCADE,
cid TEXT NOT NULL UNIQUE, -- Content ID of UCAN (for dedup)
issuer TEXT NOT NULL, -- iss: DID of issuer
audience TEXT NOT NULL, -- aud: DID of recipient
subject TEXT, -- sub: DID token is about (optional)
capabilities TEXT NOT NULL, -- JSON array of capabilities
proof_chain TEXT DEFAULT '[]', -- JSON array of parent UCAN CIDs
not_before TEXT, -- nbf: validity start
expires_at TEXT NOT NULL, -- exp: expiration time
nonce TEXT, -- Replay protection
facts TEXT DEFAULT '{}', -- Additional facts (JSON)
signature TEXT NOT NULL, -- Base64 encoded signature
raw_token TEXT NOT NULL, -- Full encoded UCAN token
is_revoked INTEGER NOT NULL DEFAULT 0,
created_at TEXT NOT NULL DEFAULT (datetime('now'))
);
CREATE INDEX idx_ucan_tokens_did_id ON ucan_tokens(did_id);
CREATE INDEX idx_ucan_tokens_issuer ON ucan_tokens(issuer);
CREATE INDEX idx_ucan_tokens_audience ON ucan_tokens(audience);
CREATE INDEX idx_ucan_tokens_expires_at ON ucan_tokens(expires_at);
-- UCAN Revocations: Revoked UCAN tokens
CREATE TABLE IF NOT EXISTS ucan_revocations (
id INTEGER PRIMARY KEY,
ucan_cid TEXT NOT NULL UNIQUE, -- CID of revoked UCAN
revoked_by TEXT NOT NULL, -- DID that revoked
reason TEXT,
revoked_at TEXT NOT NULL DEFAULT (datetime('now'))
);
CREATE INDEX idx_ucan_revocations_cid ON ucan_revocations(ucan_cid);
-- =============================================================================
-- DEVICE SESSIONS
-- =============================================================================
-- Sessions: Active device sessions
CREATE TABLE IF NOT EXISTS sessions (
id INTEGER PRIMARY KEY,
did_id INTEGER NOT NULL REFERENCES did_documents(id) ON DELETE CASCADE,
credential_id INTEGER NOT NULL REFERENCES credentials(id) ON DELETE CASCADE,
session_id TEXT NOT NULL UNIQUE, -- Opaque session identifier
device_info TEXT DEFAULT '{}', -- JSON: {browser, os, ip, etc.}
is_current INTEGER NOT NULL DEFAULT 0, -- Is this the current session
last_activity TEXT NOT NULL DEFAULT (datetime('now')),
expires_at TEXT NOT NULL,
created_at TEXT NOT NULL DEFAULT (datetime('now'))
);
CREATE INDEX idx_sessions_did_id ON sessions(did_id);
CREATE INDEX idx_sessions_session_id ON sessions(session_id);
CREATE INDEX idx_sessions_expires_at ON sessions(expires_at);
-- =============================================================================
-- SERVICE CONNECTIONS
-- =============================================================================
-- Services: Connected third-party services/dApps
CREATE TABLE IF NOT EXISTS services (
id INTEGER PRIMARY KEY,
origin TEXT NOT NULL UNIQUE, -- https://app.example.com
name TEXT NOT NULL,
description TEXT,
logo_url TEXT,
did TEXT, -- Service's DID (if known)
is_verified INTEGER NOT NULL DEFAULT 0,
metadata TEXT DEFAULT '{}', -- Additional service metadata
created_at TEXT NOT NULL DEFAULT (datetime('now'))
);
CREATE INDEX idx_services_origin ON services(origin);
-- Grants: User grants to services
CREATE TABLE IF NOT EXISTS grants (
id INTEGER PRIMARY KEY,
did_id INTEGER NOT NULL REFERENCES did_documents(id) ON DELETE CASCADE,
service_id INTEGER NOT NULL REFERENCES services(id) ON DELETE CASCADE,
ucan_id INTEGER REFERENCES ucan_tokens(id) ON DELETE SET NULL,
scopes TEXT NOT NULL DEFAULT '[]', -- JSON array of granted scopes
accounts TEXT NOT NULL DEFAULT '[]', -- JSON array of account IDs exposed
status TEXT NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'suspended', 'revoked')),
granted_at TEXT NOT NULL DEFAULT (datetime('now')),
last_used TEXT,
expires_at TEXT,
UNIQUE(did_id, service_id)
);
CREATE INDEX idx_grants_did_id ON grants(did_id);
CREATE INDEX idx_grants_service_id ON grants(service_id);
CREATE INDEX idx_grants_status ON grants(status);
-- =============================================================================
-- CAPABILITY DELEGATIONS
-- =============================================================================
-- Delegations: Capability delegation chains
CREATE TABLE IF NOT EXISTS delegations (
id INTEGER PRIMARY KEY,
did_id INTEGER NOT NULL REFERENCES did_documents(id) ON DELETE CASCADE,
ucan_id INTEGER NOT NULL REFERENCES ucan_tokens(id) ON DELETE CASCADE,
delegator TEXT NOT NULL, -- DID that delegated
delegate TEXT NOT NULL, -- DID that received delegation
resource TEXT NOT NULL, -- Resource URI (e.g., "sonr://vault/*")
action TEXT NOT NULL, -- Action (e.g., "sign", "read", "write")
caveats TEXT DEFAULT '{}', -- JSON: restrictions/conditions
parent_id INTEGER REFERENCES delegations(id), -- Parent delegation (for chains)
depth INTEGER NOT NULL DEFAULT 0, -- Delegation depth (0 = root)
status TEXT NOT NULL DEFAULT 'active' CHECK (status IN ('active', 'revoked', 'expired')),
created_at TEXT NOT NULL DEFAULT (datetime('now')),
expires_at TEXT
);
CREATE INDEX idx_delegations_did_id ON delegations(did_id);
CREATE INDEX idx_delegations_delegator ON delegations(delegator);
CREATE INDEX idx_delegations_delegate ON delegations(delegate);
CREATE INDEX idx_delegations_resource ON delegations(resource);
-- =============================================================================
-- SYNC STATE
-- =============================================================================
-- Sync Checkpoints: Track sync state with Sonr protocol
CREATE TABLE IF NOT EXISTS sync_checkpoints (
id INTEGER PRIMARY KEY,
did_id INTEGER NOT NULL REFERENCES did_documents(id) ON DELETE CASCADE,
resource_type TEXT NOT NULL, -- 'did', 'credentials', 'grants', etc.
last_block INTEGER NOT NULL DEFAULT 0, -- Last synced block height
last_tx_hash TEXT, -- Last processed transaction
last_synced TEXT NOT NULL DEFAULT (datetime('now')),
UNIQUE(did_id, resource_type)
);
CREATE INDEX idx_sync_checkpoints_did_id ON sync_checkpoints(did_id);
-- =============================================================================
-- TRIGGERS
-- =============================================================================
CREATE TRIGGER IF NOT EXISTS did_documents_updated_at
AFTER UPDATE ON did_documents
BEGIN
UPDATE did_documents SET updated_at = datetime('now') WHERE id = NEW.id;
END;