rspace-online/modules/inbox/db/schema.sql

141 lines
5.1 KiB
SQL

-- rInbox schema: collaborative email with multisig approval
CREATE SCHEMA IF NOT EXISTS rinbox;
-- Users (synced from EncryptID)
CREATE TABLE IF NOT EXISTS rinbox.users (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
did TEXT UNIQUE NOT NULL,
username TEXT,
email TEXT,
created_at TIMESTAMPTZ DEFAULT NOW()
);
-- Workspaces (org/community container)
CREATE TABLE IF NOT EXISTS rinbox.workspaces (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
slug TEXT UNIQUE NOT NULL,
name TEXT NOT NULL,
description TEXT,
owner_did TEXT NOT NULL,
created_at TIMESTAMPTZ DEFAULT NOW()
);
-- Workspace members
CREATE TABLE IF NOT EXISTS rinbox.workspace_members (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
workspace_id UUID NOT NULL REFERENCES rinbox.workspaces(id) ON DELETE CASCADE,
user_id UUID NOT NULL REFERENCES rinbox.users(id) ON DELETE CASCADE,
role TEXT NOT NULL DEFAULT 'MEMBER' CHECK (role IN ('MEMBER', 'ADMIN', 'OWNER')),
joined_at TIMESTAMPTZ DEFAULT NOW(),
UNIQUE(workspace_id, user_id)
);
-- Mailboxes (shared inboxes)
CREATE TABLE IF NOT EXISTS rinbox.mailboxes (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
workspace_id UUID REFERENCES rinbox.workspaces(id) ON DELETE CASCADE,
slug TEXT UNIQUE NOT NULL,
name TEXT NOT NULL,
email TEXT NOT NULL,
description TEXT,
visibility TEXT NOT NULL DEFAULT 'members_only' CHECK (visibility IN ('public', 'public_read', 'authenticated', 'members_only')),
owner_did TEXT NOT NULL,
-- IMAP config (encrypted in production)
imap_host TEXT,
imap_port INTEGER DEFAULT 993,
imap_user TEXT,
-- Safe multisig config
safe_address TEXT,
safe_chain_id INTEGER,
approval_threshold INTEGER DEFAULT 1,
created_at TIMESTAMPTZ DEFAULT NOW()
);
-- Mailbox members with role hierarchy
CREATE TABLE IF NOT EXISTS rinbox.mailbox_members (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
mailbox_id UUID NOT NULL REFERENCES rinbox.mailboxes(id) ON DELETE CASCADE,
user_id UUID NOT NULL REFERENCES rinbox.users(id) ON DELETE CASCADE,
role TEXT NOT NULL DEFAULT 'VIEWER' CHECK (role IN ('VIEWER', 'COMMENTER', 'DRAFTER', 'SIGNER', 'ADMIN')),
joined_at TIMESTAMPTZ DEFAULT NOW(),
UNIQUE(mailbox_id, user_id)
);
-- Email threads (synced from IMAP)
CREATE TABLE IF NOT EXISTS rinbox.threads (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
mailbox_id UUID NOT NULL REFERENCES rinbox.mailboxes(id) ON DELETE CASCADE,
message_id TEXT,
subject TEXT NOT NULL DEFAULT '(no subject)',
from_address TEXT,
from_name TEXT,
to_addresses JSONB DEFAULT '[]',
cc_addresses JSONB DEFAULT '[]',
body_text TEXT,
body_html TEXT,
tags TEXT[] DEFAULT '{}',
status TEXT NOT NULL DEFAULT 'open' CHECK (status IN ('open', 'snoozed', 'closed')),
is_read BOOLEAN DEFAULT FALSE,
is_starred BOOLEAN DEFAULT FALSE,
assigned_to UUID REFERENCES rinbox.users(id),
has_attachments BOOLEAN DEFAULT FALSE,
received_at TIMESTAMPTZ DEFAULT NOW(),
created_at TIMESTAMPTZ DEFAULT NOW()
);
-- Thread comments (internal, not sent)
CREATE TABLE IF NOT EXISTS rinbox.comments (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
thread_id UUID NOT NULL REFERENCES rinbox.threads(id) ON DELETE CASCADE,
author_id UUID NOT NULL REFERENCES rinbox.users(id),
body TEXT NOT NULL,
mentions TEXT[] DEFAULT '{}',
created_at TIMESTAMPTZ DEFAULT NOW()
);
-- Outgoing email approvals (multisig workflow)
CREATE TABLE IF NOT EXISTS rinbox.approvals (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
mailbox_id UUID NOT NULL REFERENCES rinbox.mailboxes(id) ON DELETE CASCADE,
thread_id UUID REFERENCES rinbox.threads(id),
author_id UUID NOT NULL REFERENCES rinbox.users(id),
subject TEXT NOT NULL,
body_text TEXT,
body_html TEXT,
to_addresses JSONB DEFAULT '[]',
cc_addresses JSONB DEFAULT '[]',
status TEXT NOT NULL DEFAULT 'PENDING' CHECK (status IN ('PENDING', 'APPROVED', 'SENT', 'REJECTED', 'EXPIRED')),
required_signatures INTEGER DEFAULT 1,
safe_tx_hash TEXT,
created_at TIMESTAMPTZ DEFAULT NOW(),
resolved_at TIMESTAMPTZ
);
-- Individual signatures on approvals
CREATE TABLE IF NOT EXISTS rinbox.approval_signatures (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
approval_id UUID NOT NULL REFERENCES rinbox.approvals(id) ON DELETE CASCADE,
signer_id UUID NOT NULL REFERENCES rinbox.users(id),
vote TEXT NOT NULL CHECK (vote IN ('APPROVE', 'REJECT')),
signed_at TIMESTAMPTZ DEFAULT NOW(),
UNIQUE(approval_id, signer_id)
);
-- IMAP sync state tracking
CREATE TABLE IF NOT EXISTS rinbox.sync_state (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
mailbox_id UUID UNIQUE NOT NULL REFERENCES rinbox.mailboxes(id) ON DELETE CASCADE,
last_uid INTEGER DEFAULT 0,
uid_validity INTEGER,
last_sync_at TIMESTAMPTZ,
error TEXT
);
-- Indexes
CREATE INDEX IF NOT EXISTS idx_threads_mailbox ON rinbox.threads(mailbox_id);
CREATE INDEX IF NOT EXISTS idx_threads_mailbox_status ON rinbox.threads(mailbox_id, status);
CREATE INDEX IF NOT EXISTS idx_threads_received ON rinbox.threads(mailbox_id, received_at DESC);
CREATE INDEX IF NOT EXISTS idx_comments_thread ON rinbox.comments(thread_id);
CREATE INDEX IF NOT EXISTS idx_approvals_mailbox ON rinbox.approvals(mailbox_id, status);
CREATE INDEX IF NOT EXISTS idx_approval_sigs ON rinbox.approval_signatures(approval_id);