init(db): add database schema and queries for enclave data storage
This commit is contained in:
339
db/query.sql
Normal file
339
db/query.sql
Normal file
@@ -0,0 +1,339 @@
|
||||
-- =============================================================================
|
||||
-- DID DOCUMENT QUERIES
|
||||
-- =============================================================================
|
||||
|
||||
-- name: GetDIDByDID :one
|
||||
SELECT * FROM did_documents WHERE did = ? LIMIT 1;
|
||||
|
||||
-- name: GetDIDByID :one
|
||||
SELECT * FROM did_documents WHERE id = ? LIMIT 1;
|
||||
|
||||
-- name: CreateDID :one
|
||||
INSERT INTO did_documents (did, controller, document, sequence)
|
||||
VALUES (?, ?, ?, ?)
|
||||
RETURNING *;
|
||||
|
||||
-- name: UpdateDIDDocument :exec
|
||||
UPDATE did_documents
|
||||
SET document = ?, sequence = ?, last_synced = datetime('now')
|
||||
WHERE id = ?;
|
||||
|
||||
-- name: ListAllDIDs :many
|
||||
SELECT * FROM did_documents ORDER BY created_at DESC;
|
||||
|
||||
-- =============================================================================
|
||||
-- VERIFICATION METHOD QUERIES
|
||||
-- =============================================================================
|
||||
|
||||
-- name: ListVerificationMethods :many
|
||||
SELECT * FROM verification_methods WHERE did_id = ? ORDER BY created_at;
|
||||
|
||||
-- name: GetVerificationMethod :one
|
||||
SELECT * FROM verification_methods WHERE did_id = ? AND method_id = ? LIMIT 1;
|
||||
|
||||
-- name: CreateVerificationMethod :one
|
||||
INSERT INTO verification_methods (did_id, method_id, method_type, controller, public_key, purpose)
|
||||
VALUES (?, ?, ?, ?, ?, ?)
|
||||
RETURNING *;
|
||||
|
||||
-- name: DeleteVerificationMethod :exec
|
||||
DELETE FROM verification_methods WHERE id = ?;
|
||||
|
||||
-- =============================================================================
|
||||
-- CREDENTIAL QUERIES
|
||||
-- =============================================================================
|
||||
|
||||
-- name: ListCredentialsByDID :many
|
||||
SELECT * FROM credentials WHERE did_id = ? ORDER BY last_used DESC;
|
||||
|
||||
-- name: GetCredentialByID :one
|
||||
SELECT * FROM credentials WHERE credential_id = ? LIMIT 1;
|
||||
|
||||
-- name: CreateCredential :one
|
||||
INSERT INTO credentials (
|
||||
did_id, credential_id, public_key, public_key_alg, aaguid,
|
||||
transports, device_name, device_type, authenticator, is_discoverable, backed_up
|
||||
)
|
||||
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?)
|
||||
RETURNING *;
|
||||
|
||||
-- name: UpdateCredentialCounter :exec
|
||||
UPDATE credentials
|
||||
SET sign_count = ?, last_used = datetime('now')
|
||||
WHERE id = ?;
|
||||
|
||||
-- name: RenameCredential :exec
|
||||
UPDATE credentials SET device_name = ? WHERE id = ?;
|
||||
|
||||
-- name: DeleteCredential :exec
|
||||
DELETE FROM credentials WHERE id = ? AND did_id = ?;
|
||||
|
||||
-- name: CountCredentialsByDID :one
|
||||
SELECT COUNT(*) FROM credentials WHERE did_id = ?;
|
||||
|
||||
-- =============================================================================
|
||||
-- KEY SHARE QUERIES
|
||||
-- =============================================================================
|
||||
|
||||
-- name: ListKeySharesByDID :many
|
||||
SELECT * FROM key_shares WHERE did_id = ? AND status = 'active' ORDER BY created_at;
|
||||
|
||||
-- name: GetKeyShareByID :one
|
||||
SELECT * FROM key_shares WHERE share_id = ? LIMIT 1;
|
||||
|
||||
-- name: GetKeyShareByKeyID :one
|
||||
SELECT * FROM key_shares WHERE did_id = ? AND key_id = ? AND status = 'active' LIMIT 1;
|
||||
|
||||
-- name: CreateKeyShare :one
|
||||
INSERT INTO key_shares (
|
||||
did_id, share_id, key_id, party_index, threshold, total_parties,
|
||||
curve, share_data, public_key, chain_code, derivation_path
|
||||
)
|
||||
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?)
|
||||
RETURNING *;
|
||||
|
||||
-- name: RotateKeyShare :exec
|
||||
UPDATE key_shares
|
||||
SET status = 'rotating', rotated_at = datetime('now')
|
||||
WHERE id = ?;
|
||||
|
||||
-- name: ArchiveKeyShare :exec
|
||||
UPDATE key_shares SET status = 'archived' WHERE id = ?;
|
||||
|
||||
-- name: DeleteKeyShare :exec
|
||||
DELETE FROM key_shares WHERE id = ? AND did_id = ?;
|
||||
|
||||
-- =============================================================================
|
||||
-- ACCOUNT QUERIES
|
||||
-- =============================================================================
|
||||
|
||||
-- name: ListAccountsByDID :many
|
||||
SELECT a.*, k.public_key, k.curve
|
||||
FROM accounts a
|
||||
JOIN key_shares k ON a.key_share_id = k.id
|
||||
WHERE a.did_id = ?
|
||||
ORDER BY a.is_default DESC, a.created_at;
|
||||
|
||||
-- name: ListAccountsByChain :many
|
||||
SELECT * FROM accounts WHERE did_id = ? AND chain_id = ? ORDER BY account_index, address_index;
|
||||
|
||||
-- name: GetAccountByAddress :one
|
||||
SELECT * FROM accounts WHERE address = ? LIMIT 1;
|
||||
|
||||
-- name: GetDefaultAccount :one
|
||||
SELECT * FROM accounts WHERE did_id = ? AND chain_id = ? AND is_default = 1 LIMIT 1;
|
||||
|
||||
-- name: CreateAccount :one
|
||||
INSERT INTO accounts (did_id, key_share_id, address, chain_id, coin_type, account_index, address_index, label)
|
||||
VALUES (?, ?, ?, ?, ?, ?, ?, ?)
|
||||
RETURNING *;
|
||||
|
||||
-- name: SetDefaultAccount :exec
|
||||
UPDATE accounts
|
||||
SET is_default = CASE WHEN id = ? THEN 1 ELSE 0 END
|
||||
WHERE did_id = ? AND chain_id = ?;
|
||||
|
||||
-- name: UpdateAccountLabel :exec
|
||||
UPDATE accounts SET label = ? WHERE id = ?;
|
||||
|
||||
-- name: DeleteAccount :exec
|
||||
DELETE FROM accounts WHERE id = ? AND did_id = ?;
|
||||
|
||||
-- =============================================================================
|
||||
-- UCAN TOKEN QUERIES
|
||||
-- =============================================================================
|
||||
|
||||
-- name: ListUCANsByDID :many
|
||||
SELECT * FROM ucan_tokens
|
||||
WHERE did_id = ? AND is_revoked = 0 AND expires_at > datetime('now')
|
||||
ORDER BY created_at DESC;
|
||||
|
||||
-- name: ListUCANsByAudience :many
|
||||
SELECT * FROM ucan_tokens
|
||||
WHERE audience = ? AND is_revoked = 0 AND expires_at > datetime('now')
|
||||
ORDER BY created_at DESC;
|
||||
|
||||
-- name: GetUCANByCID :one
|
||||
SELECT * FROM ucan_tokens WHERE cid = ? LIMIT 1;
|
||||
|
||||
-- name: CreateUCAN :one
|
||||
INSERT INTO ucan_tokens (
|
||||
did_id, cid, issuer, audience, subject, capabilities,
|
||||
proof_chain, not_before, expires_at, nonce, facts, signature, raw_token
|
||||
)
|
||||
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?)
|
||||
RETURNING *;
|
||||
|
||||
-- name: RevokeUCAN :exec
|
||||
UPDATE ucan_tokens SET is_revoked = 1 WHERE cid = ?;
|
||||
|
||||
-- name: IsUCANRevoked :one
|
||||
SELECT EXISTS(SELECT 1 FROM ucan_revocations WHERE ucan_cid = ?) as revoked;
|
||||
|
||||
-- name: CreateRevocation :exec
|
||||
INSERT INTO ucan_revocations (ucan_cid, revoked_by, reason)
|
||||
VALUES (?, ?, ?);
|
||||
|
||||
-- name: CleanExpiredUCANs :exec
|
||||
DELETE FROM ucan_tokens WHERE expires_at < datetime('now', '-30 days');
|
||||
|
||||
-- =============================================================================
|
||||
-- SESSION QUERIES
|
||||
-- =============================================================================
|
||||
|
||||
-- name: ListSessionsByDID :many
|
||||
SELECT s.*, c.device_name, c.authenticator
|
||||
FROM sessions s
|
||||
JOIN credentials c ON s.credential_id = c.id
|
||||
WHERE s.did_id = ? AND s.expires_at > datetime('now')
|
||||
ORDER BY s.last_activity DESC;
|
||||
|
||||
-- name: GetSessionByID :one
|
||||
SELECT * FROM sessions WHERE session_id = ? LIMIT 1;
|
||||
|
||||
-- name: GetCurrentSession :one
|
||||
SELECT * FROM sessions WHERE did_id = ? AND is_current = 1 LIMIT 1;
|
||||
|
||||
-- name: CreateSession :one
|
||||
INSERT INTO sessions (did_id, credential_id, session_id, device_info, is_current, expires_at)
|
||||
VALUES (?, ?, ?, ?, ?, ?)
|
||||
RETURNING *;
|
||||
|
||||
-- name: UpdateSessionActivity :exec
|
||||
UPDATE sessions SET last_activity = datetime('now') WHERE id = ?;
|
||||
|
||||
-- name: SetCurrentSession :exec
|
||||
UPDATE sessions
|
||||
SET is_current = CASE WHEN id = ? THEN 1 ELSE 0 END
|
||||
WHERE did_id = ?;
|
||||
|
||||
-- name: DeleteSession :exec
|
||||
DELETE FROM sessions WHERE id = ?;
|
||||
|
||||
-- name: DeleteExpiredSessions :exec
|
||||
DELETE FROM sessions WHERE expires_at < datetime('now');
|
||||
|
||||
-- =============================================================================
|
||||
-- SERVICE QUERIES
|
||||
-- =============================================================================
|
||||
|
||||
-- name: GetServiceByOrigin :one
|
||||
SELECT * FROM services WHERE origin = ? LIMIT 1;
|
||||
|
||||
-- name: GetServiceByID :one
|
||||
SELECT * FROM services WHERE id = ? LIMIT 1;
|
||||
|
||||
-- name: CreateService :one
|
||||
INSERT INTO services (origin, name, description, logo_url, did, is_verified, metadata)
|
||||
VALUES (?, ?, ?, ?, ?, ?, ?)
|
||||
RETURNING *;
|
||||
|
||||
-- name: UpdateService :exec
|
||||
UPDATE services
|
||||
SET name = ?, description = ?, logo_url = ?, metadata = ?
|
||||
WHERE id = ?;
|
||||
|
||||
-- name: ListVerifiedServices :many
|
||||
SELECT * FROM services WHERE is_verified = 1 ORDER BY name;
|
||||
|
||||
-- =============================================================================
|
||||
-- GRANT QUERIES
|
||||
-- =============================================================================
|
||||
|
||||
-- name: ListGrantsByDID :many
|
||||
SELECT g.*, s.name as service_name, s.origin as service_origin, s.logo_url as service_logo
|
||||
FROM grants g
|
||||
JOIN services s ON g.service_id = s.id
|
||||
WHERE g.did_id = ? AND g.status = 'active'
|
||||
ORDER BY g.last_used DESC NULLS LAST;
|
||||
|
||||
-- name: GetGrantByService :one
|
||||
SELECT * FROM grants WHERE did_id = ? AND service_id = ? LIMIT 1;
|
||||
|
||||
-- name: CreateGrant :one
|
||||
INSERT INTO grants (did_id, service_id, ucan_id, scopes, accounts, expires_at)
|
||||
VALUES (?, ?, ?, ?, ?, ?)
|
||||
RETURNING *;
|
||||
|
||||
-- name: UpdateGrantScopes :exec
|
||||
UPDATE grants SET scopes = ?, accounts = ? WHERE id = ?;
|
||||
|
||||
-- name: UpdateGrantLastUsed :exec
|
||||
UPDATE grants SET last_used = datetime('now') WHERE id = ?;
|
||||
|
||||
-- name: RevokeGrant :exec
|
||||
UPDATE grants SET status = 'revoked' WHERE id = ?;
|
||||
|
||||
-- name: SuspendGrant :exec
|
||||
UPDATE grants SET status = 'suspended' WHERE id = ?;
|
||||
|
||||
-- name: ReactivateGrant :exec
|
||||
UPDATE grants SET status = 'active' WHERE id = ? AND status = 'suspended';
|
||||
|
||||
-- name: CountActiveGrants :one
|
||||
SELECT COUNT(*) FROM grants WHERE did_id = ? AND status = 'active';
|
||||
|
||||
-- =============================================================================
|
||||
-- DELEGATION QUERIES
|
||||
-- =============================================================================
|
||||
|
||||
-- name: ListDelegationsByDelegator :many
|
||||
SELECT * FROM delegations
|
||||
WHERE delegator = ? AND status = 'active'
|
||||
ORDER BY created_at DESC;
|
||||
|
||||
-- name: ListDelegationsByDelegate :many
|
||||
SELECT * FROM delegations
|
||||
WHERE delegate = ? AND status = 'active' AND (expires_at IS NULL OR expires_at > datetime('now'))
|
||||
ORDER BY created_at DESC;
|
||||
|
||||
-- name: ListDelegationsForResource :many
|
||||
SELECT * FROM delegations
|
||||
WHERE did_id = ? AND resource = ? AND status = 'active'
|
||||
ORDER BY depth, created_at;
|
||||
|
||||
-- name: GetDelegationChain :many
|
||||
WITH RECURSIVE chain AS (
|
||||
SELECT * FROM delegations WHERE id = ?
|
||||
UNION ALL
|
||||
SELECT d.* FROM delegations d
|
||||
JOIN chain c ON d.id = c.parent_id
|
||||
)
|
||||
SELECT * FROM chain ORDER BY depth DESC;
|
||||
|
||||
-- name: CreateDelegation :one
|
||||
INSERT INTO delegations (
|
||||
did_id, ucan_id, delegator, delegate, resource, action, caveats, parent_id, depth, expires_at
|
||||
)
|
||||
VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?)
|
||||
RETURNING *;
|
||||
|
||||
-- name: RevokeDelegation :exec
|
||||
UPDATE delegations SET status = 'revoked' WHERE id = ?;
|
||||
|
||||
-- name: RevokeDelegationChain :exec
|
||||
WITH RECURSIVE chain AS (
|
||||
SELECT id FROM delegations WHERE id = ?
|
||||
UNION ALL
|
||||
SELECT d.id FROM delegations d
|
||||
JOIN chain c ON d.parent_id = c.id
|
||||
)
|
||||
UPDATE delegations SET status = 'revoked' WHERE id IN (SELECT id FROM chain);
|
||||
|
||||
-- =============================================================================
|
||||
-- SYNC QUERIES
|
||||
-- =============================================================================
|
||||
|
||||
-- name: GetSyncCheckpoint :one
|
||||
SELECT * FROM sync_checkpoints WHERE did_id = ? AND resource_type = ? LIMIT 1;
|
||||
|
||||
-- name: UpsertSyncCheckpoint :exec
|
||||
INSERT INTO sync_checkpoints (did_id, resource_type, last_block, last_tx_hash)
|
||||
VALUES (?, ?, ?, ?)
|
||||
ON CONFLICT(did_id, resource_type) DO UPDATE SET
|
||||
last_block = excluded.last_block,
|
||||
last_tx_hash = excluded.last_tx_hash,
|
||||
last_synced = datetime('now');
|
||||
|
||||
-- name: ListSyncCheckpoints :many
|
||||
SELECT * FROM sync_checkpoints WHERE did_id = ?;
|
||||
264
db/schema.sql
Normal file
264
db/schema.sql
Normal file
@@ -0,0 +1,264 @@
|
||||
-- =============================================================================
|
||||
-- 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;
|
||||
Reference in New Issue
Block a user