340 lines
11 KiB
SQL
340 lines
11 KiB
SQL
-- =============================================================================
|
|
-- 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 = ?;
|