sojorn/go-backend/internal/database/migrations/000003_e2ee_backup_recovery.up.sql
Patrick Britton 3c4680bdd7 Initial commit: Complete threaded conversation system with inline replies
**Major Features Added:**
- **Inline Reply System**: Replace compose screen with inline reply boxes
- **Thread Navigation**: Parent/child navigation with jump functionality
- **Chain Flow UI**: Reply counts, expand/collapse animations, visual hierarchy
- **Enhanced Animations**: Smooth transitions, hover effects, micro-interactions

 **Frontend Changes:**
- **ThreadedCommentWidget**: Complete rewrite with animations and navigation
- **ThreadNode Model**: Added parent references and descendant counting
- **ThreadedConversationScreen**: Integrated navigation handlers
- **PostDetailScreen**: Replaced with threaded conversation view
- **ComposeScreen**: Added reply indicators and context
- **PostActions**: Fixed visibility checks for chain buttons

 **Backend Changes:**
- **API Route**: Added /posts/:id/thread endpoint
- **Post Repository**: Include allow_chain and visibility fields in feed
- **Thread Handler**: Support for fetching post chains

 **UI/UX Improvements:**
- **Reply Context**: Clear indication when replying to specific posts
- **Character Counting**: 500 character limit with live counter
- **Visual Hierarchy**: Depth-based indentation and styling
- **Smooth Animations**: SizeTransition, FadeTransition, hover states
- **Chain Navigation**: Parent/child buttons with visual feedback

 **Technical Enhancements:**
- **Animation Controllers**: Proper lifecycle management
- **State Management**: Clean separation of concerns
- **Navigation Callbacks**: Reusable navigation system
- **Error Handling**: Graceful fallbacks and user feedback

This creates a Reddit-style threaded conversation experience with smooth
animations, inline replies, and intuitive navigation between posts in a chain.
2026-01-30 07:40:19 -06:00

137 lines
6 KiB
SQL

-- E2EE Backup & Recovery System Migration
-- Creates tables for device sync, cloud backups, and social recovery
-- Sync codes table for device-to-device pairing
CREATE TABLE IF NOT EXISTS sync_codes (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
code VARCHAR(6) NOT NULL,
device_fingerprint TEXT,
device_name TEXT,
expires_at TIMESTAMP NOT NULL,
used_at TIMESTAMP,
attempts INT DEFAULT 0,
created_at TIMESTAMP DEFAULT NOW()
);
-- Indexes for sync codes
CREATE INDEX IF NOT EXISTS idx_sync_codes_code ON sync_codes(code) WHERE used_at IS NULL;
CREATE INDEX IF NOT EXISTS idx_sync_codes_expires ON sync_codes(expires_at) WHERE used_at IS NULL;
CREATE INDEX IF NOT EXISTS idx_sync_codes_user ON sync_codes(user_id, created_at DESC);
-- Cloud backups table
CREATE TABLE IF NOT EXISTS cloud_backups (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
encrypted_blob BYTEA NOT NULL,
salt BYTEA NOT NULL,
nonce BYTEA NOT NULL,
mac BYTEA NOT NULL,
version INT DEFAULT 1,
device_name TEXT,
size_bytes BIGINT,
created_at TIMESTAMP DEFAULT NOW()
);
-- Indexes for cloud backups
CREATE INDEX IF NOT EXISTS idx_backups_user ON cloud_backups(user_id, created_at DESC);
CREATE INDEX IF NOT EXISTS idx_backups_version ON cloud_backups(user_id, version);
-- Recovery guardians table for social recovery
CREATE TABLE IF NOT EXISTS recovery_guardians (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
guardian_user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
shard_encrypted BYTEA NOT NULL,
shard_index INT NOT NULL,
status VARCHAR(20) DEFAULT 'pending' CHECK (status IN ('pending', 'accepted', 'declined', 'revoked')),
invited_at TIMESTAMP DEFAULT NOW(),
responded_at TIMESTAMP,
created_at TIMESTAMP DEFAULT NOW()
);
-- Indexes for recovery guardians
CREATE INDEX IF NOT EXISTS idx_guardians_user ON recovery_guardians(user_id);
CREATE INDEX IF NOT EXISTS idx_guardians_guardian ON recovery_guardians(guardian_user_id);
CREATE INDEX IF NOT EXISTS idx_guardians_status ON recovery_guardians(status);
-- Recovery sessions table
CREATE TABLE IF NOT EXISTS recovery_sessions (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
method VARCHAR(20) NOT NULL CHECK (method IN ('social', 'email', 'questions')),
shards_received INT DEFAULT 0,
shards_needed INT NOT NULL,
status VARCHAR(20) DEFAULT 'pending' CHECK (status IN ('pending', 'in_progress', 'completed', 'expired', 'failed')),
expires_at TIMESTAMP NOT NULL,
completed_at TIMESTAMP,
created_at TIMESTAMP DEFAULT NOW()
);
-- Indexes for recovery sessions
CREATE INDEX IF NOT EXISTS idx_sessions_user ON recovery_sessions(user_id, created_at DESC);
CREATE INDEX IF NOT EXISTS idx_sessions_status ON recovery_sessions(status);
CREATE INDEX IF NOT EXISTS idx_sessions_expires ON recovery_sessions(expires_at);
-- Recovery shard submissions table
CREATE TABLE IF NOT EXISTS recovery_shard_submissions (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
session_id UUID NOT NULL REFERENCES public.recovery_sessions(id) ON DELETE CASCADE,
guardian_user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
shard_encrypted BYTEA NOT NULL,
submitted_at TIMESTAMP DEFAULT NOW(),
created_at TIMESTAMP DEFAULT NOW()
);
-- Indexes for shard submissions
CREATE INDEX IF NOT EXISTS idx_shards_session ON recovery_shard_submissions(session_id);
CREATE INDEX IF NOT EXISTS idx_shards_guardian ON recovery_shard_submissions(guardian_user_id);
-- User backup preferences table
CREATE TABLE IF NOT EXISTS backup_preferences (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
cloud_backup_enabled BOOLEAN DEFAULT false,
auto_backup_enabled BOOLEAN DEFAULT false,
backup_frequency_hours INT DEFAULT 24,
last_backup_at TIMESTAMP,
backup_password_hash TEXT, -- Argon2id hash of backup password
backup_salt BYTEA, -- Salt for backup password derivation
created_at TIMESTAMP DEFAULT NOW(),
updated_at TIMESTAMP DEFAULT NOW()
);
-- Index for backup preferences
CREATE INDEX IF NOT EXISTS idx_backup_preferences_user ON backup_preferences(user_id);
-- Device registry table for tracking user devices
CREATE TABLE IF NOT EXISTS user_devices (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID NOT NULL REFERENCES public.users(id) ON DELETE CASCADE,
device_fingerprint TEXT NOT NULL,
device_name TEXT,
device_type VARCHAR(20) CHECK (device_type IN ('android', 'ios', 'web', 'desktop')),
last_seen_at TIMESTAMP,
is_active BOOLEAN DEFAULT true,
created_at TIMESTAMP DEFAULT NOW()
);
-- Indexes for user devices
CREATE INDEX IF NOT EXISTS idx_devices_user ON user_devices(user_id);
CREATE INDEX IF NOT EXISTS idx_devices_fingerprint ON user_devices(device_fingerprint);
CREATE INDEX IF NOT EXISTS idx_devices_active ON user_devices(user_id, is_active);
-- Insert default backup preferences for existing users
INSERT INTO backup_preferences (user_id)
SELECT id FROM public.users
WHERE id NOT IN (SELECT user_id FROM backup_preferences);
-- Comments for documentation
COMMENT ON TABLE sync_codes IS 'Stores temporary 6-digit codes for device-to-device sync pairing';
COMMENT ON TABLE cloud_backups IS 'Stores encrypted user backup blobs in Firebase Storage';
COMMENT ON TABLE recovery_guardians IS 'Stores encrypted key shards for social recovery';
COMMENT ON TABLE recovery_sessions IS 'Tracks recovery attempts and progress';
COMMENT ON TABLE recovery_shard_submissions IS 'Stores individual shard submissions during recovery';
COMMENT ON TABLE backup_preferences IS 'User preferences for backup settings';
COMMENT ON TABLE user_devices IS 'Registry of user devices for sync management';