-- EncryptID PostgreSQL Schema -- Run once to initialize the database CREATE TABLE IF NOT EXISTS users ( id TEXT PRIMARY KEY, username TEXT UNIQUE NOT NULL, display_name TEXT, did TEXT, email TEXT, created_at TIMESTAMPTZ DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_users_email ON users(email); -- Profile columns (added for user profile management) ALTER TABLE users ADD COLUMN IF NOT EXISTS bio TEXT; ALTER TABLE users ADD COLUMN IF NOT EXISTS avatar_url TEXT; ALTER TABLE users ADD COLUMN IF NOT EXISTS profile_email TEXT; ALTER TABLE users ADD COLUMN IF NOT EXISTS profile_email_is_recovery BOOLEAN DEFAULT FALSE; ALTER TABLE users ADD COLUMN IF NOT EXISTS wallet_address TEXT; ALTER TABLE users ADD COLUMN IF NOT EXISTS updated_at TIMESTAMPTZ DEFAULT NOW(); CREATE TABLE IF NOT EXISTS credentials ( credential_id TEXT PRIMARY KEY, user_id TEXT NOT NULL REFERENCES users(id) ON DELETE CASCADE, public_key TEXT NOT NULL, counter INTEGER DEFAULT 0, transports TEXT[], created_at TIMESTAMPTZ DEFAULT NOW(), last_used TIMESTAMPTZ ); CREATE INDEX IF NOT EXISTS idx_credentials_user_id ON credentials(user_id); CREATE TABLE IF NOT EXISTS challenges ( challenge TEXT PRIMARY KEY, user_id TEXT, type TEXT NOT NULL CHECK (type IN ('registration', 'authentication')), created_at TIMESTAMPTZ DEFAULT NOW(), expires_at TIMESTAMPTZ NOT NULL ); -- Auto-clean expired challenges (run periodically or use pg_cron) CREATE INDEX IF NOT EXISTS idx_challenges_expires_at ON challenges(expires_at); CREATE TABLE IF NOT EXISTS recovery_tokens ( token TEXT PRIMARY KEY, user_id TEXT NOT NULL REFERENCES users(id) ON DELETE CASCADE, type TEXT NOT NULL CHECK (type IN ('email_verify', 'account_recovery')), created_at TIMESTAMPTZ DEFAULT NOW(), expires_at TIMESTAMPTZ NOT NULL, used BOOLEAN DEFAULT FALSE ); CREATE INDEX IF NOT EXISTS idx_recovery_tokens_user_id ON recovery_tokens(user_id); CREATE INDEX IF NOT EXISTS idx_recovery_tokens_expires_at ON recovery_tokens(expires_at); -- Space membership: source of truth for user roles across the r*.online ecosystem CREATE TABLE IF NOT EXISTS space_members ( space_slug TEXT NOT NULL, user_did TEXT NOT NULL, role TEXT NOT NULL CHECK (role IN ('viewer', 'participant', 'moderator', 'admin')), joined_at TIMESTAMPTZ DEFAULT NOW(), granted_by TEXT, PRIMARY KEY (space_slug, user_did) ); CREATE INDEX IF NOT EXISTS idx_space_members_user_did ON space_members(user_did); CREATE INDEX IF NOT EXISTS idx_space_members_space_slug ON space_members(space_slug); -- ============================================================================ -- GUARDIAN RECOVERY (2-of-3 social recovery) -- ============================================================================ -- Guardians: up to 3 trusted contacts per account CREATE TABLE IF NOT EXISTS guardians ( id TEXT PRIMARY KEY, user_id TEXT NOT NULL REFERENCES users(id) ON DELETE CASCADE, name TEXT NOT NULL, -- display name (e.g. "Mom", "Alex") email TEXT, -- for sending invite/approval emails guardian_user_id TEXT REFERENCES users(id), -- if they have an EncryptID account status TEXT NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', 'accepted', 'revoked')), invite_token TEXT UNIQUE, -- token for invite link invite_expires_at TIMESTAMPTZ, accepted_at TIMESTAMPTZ, created_at TIMESTAMPTZ DEFAULT NOW() ); CREATE INDEX IF NOT EXISTS idx_guardians_user_id ON guardians(user_id); CREATE INDEX IF NOT EXISTS idx_guardians_guardian_user_id ON guardians(guardian_user_id); CREATE INDEX IF NOT EXISTS idx_guardians_invite_token ON guardians(invite_token); -- Recovery requests: when a user needs to recover their account CREATE TABLE IF NOT EXISTS recovery_requests ( id TEXT PRIMARY KEY, user_id TEXT NOT NULL REFERENCES users(id) ON DELETE CASCADE, status TEXT NOT NULL DEFAULT 'pending' CHECK (status IN ('pending', 'approved', 'cancelled', 'completed', 'expired')), threshold INTEGER NOT NULL DEFAULT 2, -- approvals needed (2-of-3) approval_count INTEGER NOT NULL DEFAULT 0, initiated_at TIMESTAMPTZ DEFAULT NOW(), expires_at TIMESTAMPTZ NOT NULL, -- 7 days to collect approvals completed_at TIMESTAMPTZ ); CREATE INDEX IF NOT EXISTS idx_recovery_requests_user_id ON recovery_requests(user_id); -- Recovery approvals: guardian votes on a recovery request CREATE TABLE IF NOT EXISTS recovery_approvals ( request_id TEXT NOT NULL REFERENCES recovery_requests(id) ON DELETE CASCADE, guardian_id TEXT NOT NULL REFERENCES guardians(id) ON DELETE CASCADE, approval_token TEXT UNIQUE, -- token sent via email/link for one-click approve approved_at TIMESTAMPTZ, created_at TIMESTAMPTZ DEFAULT NOW(), PRIMARY KEY (request_id, guardian_id) ); CREATE INDEX IF NOT EXISTS idx_recovery_approvals_token ON recovery_approvals(approval_token); -- Device link tokens: for linking a second device via QR or email CREATE TABLE IF NOT EXISTS device_links ( token TEXT PRIMARY KEY, user_id TEXT NOT NULL REFERENCES users(id) ON DELETE CASCADE, created_at TIMESTAMPTZ DEFAULT NOW(), expires_at TIMESTAMPTZ NOT NULL, -- 10 minutes used BOOLEAN DEFAULT FALSE ); CREATE INDEX IF NOT EXISTS idx_device_links_user_id ON device_links(user_id); -- ============================================================================ -- ENCRYPTED POSTAL ADDRESSES (zero-knowledge address storage) -- ============================================================================ -- Addresses are encrypted client-side with passkey-derived AES-256-GCM keys. -- The server stores opaque ciphertext + cleartext metadata (label, isDefault) for UI listing. CREATE TABLE IF NOT EXISTS encrypted_addresses ( id TEXT NOT NULL, user_id TEXT NOT NULL REFERENCES users(id) ON DELETE CASCADE, ciphertext TEXT NOT NULL, iv TEXT NOT NULL, label TEXT NOT NULL CHECK (label IN ('home', 'work', 'shipping', 'billing', 'other')), label_custom TEXT, is_default BOOLEAN DEFAULT FALSE, created_at TIMESTAMPTZ DEFAULT NOW(), updated_at TIMESTAMPTZ DEFAULT NOW(), PRIMARY KEY (id, user_id) ); CREATE INDEX IF NOT EXISTS idx_encrypted_addresses_user_id ON encrypted_addresses(user_id);