-- Session Events table (Event Sourcing pattern - insert only, never update) -- This provides an immutable audit trail of all session state changes -- The current session state can be derived by replaying events CREATE TABLE session_events ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), session_id UUID NOT NULL, username VARCHAR(255) NOT NULL, -- The user this session belongs to event_type VARCHAR(50) NOT NULL, -- Event type: created, joined, ready, completed, failed, expired session_type VARCHAR(20) NOT NULL, -- 'keygen' or 'sign' -- Event payload (immutable snapshot at event time) threshold_n INTEGER, threshold_t INTEGER, party_id VARCHAR(255), -- For party-specific events (joined, ready, completed) party_index INTEGER, message_hash BYTEA, -- For sign sessions public_key BYTEA, -- Result of keygen signature BYTEA, -- Result of sign error_message TEXT, -- For failed events -- Metadata metadata JSONB, -- Additional event-specific data created_at TIMESTAMP NOT NULL DEFAULT NOW(), -- Constraints CONSTRAINT chk_session_event_type CHECK (event_type IN ( 'session_created', -- Session initiated 'party_joined', -- A party joined the session 'party_ready', -- A party is ready to start MPC 'round_started', -- MPC round started 'round_completed', -- MPC round completed 'session_completed', -- Session completed successfully 'session_failed', -- Session failed 'session_expired', -- Session expired 'delegate_share_sent', -- Delegate share sent to user 'signing_config_set', -- Signing parties configured 'signing_config_cleared' -- Signing parties cleared )), CONSTRAINT chk_session_event_session_type CHECK (session_type IN ('keygen', 'sign')) ); -- Indexes for efficient querying CREATE INDEX idx_session_events_session_id ON session_events(session_id); CREATE INDEX idx_session_events_username ON session_events(username); CREATE INDEX idx_session_events_created_at ON session_events(created_at); CREATE INDEX idx_session_events_event_type ON session_events(event_type); CREATE INDEX idx_session_events_session_type ON session_events(session_type); -- Composite index for common queries CREATE INDEX idx_session_events_session_timeline ON session_events(session_id, created_at); CREATE INDEX idx_session_events_user_sessions ON session_events(username, session_type, created_at DESC); -- Comments COMMENT ON TABLE session_events IS 'Immutable event log for MPC sessions - append only, never update or delete'; COMMENT ON COLUMN session_events.username IS 'The unique user identifier that links all MPC operations'; COMMENT ON COLUMN session_events.event_type IS 'Type of event that occurred'; COMMENT ON COLUMN session_events.metadata IS 'Additional JSON data specific to the event type'; -- View to get current session state by replaying events CREATE OR REPLACE VIEW session_current_state AS SELECT DISTINCT ON (session_id) session_id, username, session_type, threshold_n, threshold_t, event_type as current_status, public_key, signature, error_message, created_at as last_event_at, (SELECT MIN(created_at) FROM session_events e2 WHERE e2.session_id = session_events.session_id) as started_at FROM session_events ORDER BY session_id, created_at DESC; COMMENT ON VIEW session_current_state IS 'Derived view showing current state of each session from event log';