-- Create users table CREATE TABLE IF NOT EXISTS users ( id BIGSERIAL PRIMARY KEY, username VARCHAR(255) UNIQUE NOT NULL, password_hash VARCHAR(255), is_admin BOOLEAN DEFAULT false, is_streamer BOOLEAN DEFAULT false, is_pgp_only BOOLEAN DEFAULT false, pgp_only_enabled_at TIMESTAMP WITH TIME ZONE, bio TEXT DEFAULT '', avatar_url VARCHAR(255), user_color VARCHAR(7) NOT NULL DEFAULT '#561D5E', -- Hex color (no longer unique - allows collisions) created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Create pgp_keys table CREATE TABLE IF NOT EXISTS pgp_keys ( id BIGSERIAL PRIMARY KEY, user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE, public_key TEXT NOT NULL, fingerprint VARCHAR(40) UNIQUE NOT NULL, key_origin VARCHAR(20) DEFAULT 'imported', created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Create realms table CREATE TABLE IF NOT EXISTS realms ( id BIGSERIAL PRIMARY KEY, user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE, name VARCHAR(255) UNIQUE NOT NULL, description TEXT DEFAULT '', realm_type VARCHAR(20) DEFAULT 'stream' CHECK (realm_type IN ('stream', 'video')), stream_key VARCHAR(64) UNIQUE, is_active BOOLEAN DEFAULT true, is_live BOOLEAN DEFAULT false, viewer_count INTEGER DEFAULT 0, viewer_multiplier INTEGER DEFAULT 1, chat_enabled BOOLEAN DEFAULT true, chat_retention_hours INTEGER DEFAULT 24, chat_slow_mode_seconds INTEGER DEFAULT 0, chat_links_allowed BOOLEAN DEFAULT true, chat_subscribers_only BOOLEAN DEFAULT false, chat_guests_allowed BOOLEAN DEFAULT true, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Add description column if it doesn't exist (for existing databases) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'realms' AND column_name = 'description' ) THEN ALTER TABLE realms ADD COLUMN description TEXT DEFAULT ''; END IF; END $$; -- Add realm_type column if it doesn't exist (for existing databases) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'realms' AND column_name = 'realm_type' ) THEN ALTER TABLE realms ADD COLUMN realm_type VARCHAR(20) DEFAULT 'stream' CHECK (realm_type IN ('stream', 'video')); END IF; END $$; -- Add viewer_multiplier column if it doesn't exist (for existing databases) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'realms' AND column_name = 'viewer_multiplier' ) THEN ALTER TABLE realms ADD COLUMN viewer_multiplier INTEGER DEFAULT 1; END IF; END $$; -- Make stream_key nullable for video realms (for existing databases) DO $$ BEGIN ALTER TABLE realms ALTER COLUMN stream_key DROP NOT NULL; EXCEPTION WHEN others THEN NULL; END $$; -- Create stream_keys table (deprecated, kept for compatibility) CREATE TABLE IF NOT EXISTS stream_keys ( id BIGSERIAL PRIMARY KEY, user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE, key VARCHAR(64) UNIQUE NOT NULL, is_active BOOLEAN DEFAULT true, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Create indexes CREATE INDEX idx_users_username ON users(username); CREATE INDEX idx_users_is_streamer ON users(is_streamer); CREATE INDEX idx_users_is_pgp_only ON users(is_pgp_only); CREATE INDEX idx_users_user_color ON users(user_color); CREATE INDEX idx_pgp_keys_user_id ON pgp_keys(user_id); CREATE INDEX idx_pgp_keys_fingerprint ON pgp_keys(fingerprint); CREATE INDEX idx_realms_user_id ON realms(user_id); CREATE INDEX idx_realms_name ON realms(name); CREATE INDEX idx_realms_stream_key ON realms(stream_key); CREATE INDEX idx_realms_is_live ON realms(is_live); CREATE INDEX idx_realms_realm_type ON realms(realm_type); CREATE INDEX idx_stream_keys_user_id ON stream_keys(user_id); CREATE INDEX idx_stream_keys_key ON stream_keys(key) WHERE is_active = true; CREATE INDEX idx_stream_keys_active ON stream_keys(is_active); -- Create updated_at trigger CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = CURRENT_TIMESTAMP; RETURN NEW; END; $$ language 'plpgsql'; CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_realms_updated_at BEFORE UPDATE ON realms FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_stream_keys_updated_at BEFORE UPDATE ON stream_keys FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- Create function to deactivate old keys when a new one is created CREATE OR REPLACE FUNCTION deactivate_old_stream_keys() RETURNS TRIGGER AS $$ BEGIN IF NEW.is_active = true THEN UPDATE stream_keys SET is_active = false WHERE user_id = NEW.user_id AND id != NEW.id AND is_active = true; END IF; RETURN NEW; END; $$ language 'plpgsql'; CREATE TRIGGER deactivate_old_keys AFTER INSERT OR UPDATE ON stream_keys FOR EACH ROW EXECUTE FUNCTION deactivate_old_stream_keys(); -- Add constraint to ensure pgp_only_enabled_at is set when is_pgp_only is true CREATE OR REPLACE FUNCTION check_pgp_only_timestamp() RETURNS TRIGGER AS $$ BEGIN IF NEW.is_pgp_only = true AND NEW.pgp_only_enabled_at IS NULL THEN NEW.pgp_only_enabled_at = CURRENT_TIMESTAMP; END IF; RETURN NEW; END; $$ language 'plpgsql'; CREATE TRIGGER ensure_pgp_only_timestamp BEFORE INSERT OR UPDATE ON users FOR EACH ROW EXECUTE FUNCTION check_pgp_only_timestamp(); -- Chat moderators table CREATE TABLE IF NOT EXISTS chat_moderators ( realm_id BIGINT NOT NULL REFERENCES realms(id) ON DELETE CASCADE, user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE, granted_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, PRIMARY KEY (realm_id, user_id) ); -- Chat global settings table (singleton - only one row allowed) CREATE TABLE IF NOT EXISTS chat_settings ( id INTEGER PRIMARY KEY DEFAULT 1 CHECK (id = 1), guest_prefix VARCHAR(50) DEFAULT 'Guest', guest_id_pattern VARCHAR(100) DEFAULT '{prefix}{random}', default_retention_hours INTEGER DEFAULT 24, guests_allowed_site_wide BOOLEAN DEFAULT true, registration_enabled BOOLEAN DEFAULT true, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Add new columns if they don't exist (for existing databases) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'chat_settings' AND column_name = 'guests_allowed_site_wide' ) THEN ALTER TABLE chat_settings ADD COLUMN guests_allowed_site_wide BOOLEAN DEFAULT true; END IF; IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'chat_settings' AND column_name = 'registration_enabled' ) THEN ALTER TABLE chat_settings ADD COLUMN registration_enabled BOOLEAN DEFAULT true; END IF; END $$; -- Insert default chat settings (only one row can exist due to CHECK constraint) INSERT INTO chat_settings (id, guest_prefix, guest_id_pattern, default_retention_hours, guests_allowed_site_wide, registration_enabled) VALUES (1, 'Guest', '{prefix}{random}', 24, true, true) ON CONFLICT (id) DO UPDATE SET guest_prefix = COALESCE(EXCLUDED.guest_prefix, chat_settings.guest_prefix), guest_id_pattern = COALESCE(EXCLUDED.guest_id_pattern, chat_settings.guest_id_pattern), default_retention_hours = COALESCE(EXCLUDED.default_retention_hours, chat_settings.default_retention_hours), guests_allowed_site_wide = COALESCE(EXCLUDED.guests_allowed_site_wide, chat_settings.guests_allowed_site_wide), registration_enabled = COALESCE(EXCLUDED.registration_enabled, chat_settings.registration_enabled); -- Create chat moderators indexes CREATE INDEX idx_chat_moderators_realm_id ON chat_moderators(realm_id); CREATE INDEX idx_chat_moderators_user_id ON chat_moderators(user_id); -- Chat settings trigger CREATE TRIGGER update_chat_settings_updated_at BEFORE UPDATE ON chat_settings FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- Stickers/Emotes table CREATE TABLE IF NOT EXISTS stickers ( id BIGSERIAL PRIMARY KEY, name VARCHAR(50) UNIQUE NOT NULL, file_path VARCHAR(255) NOT NULL, is_active BOOLEAN DEFAULT true, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Create stickers index CREATE INDEX idx_stickers_name ON stickers(name); CREATE INDEX idx_stickers_active ON stickers(is_active); -- Add is_restreamer column to users table DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'users' AND column_name = 'is_restreamer' ) THEN ALTER TABLE users ADD COLUMN is_restreamer BOOLEAN DEFAULT false; END IF; END $$; -- Add banner_url column to users table DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'users' AND column_name = 'banner_url' ) THEN ALTER TABLE users ADD COLUMN banner_url VARCHAR(255); END IF; END $$; -- Add banner_position column to users table (0-100 representing Y percentage for object-position) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'users' AND column_name = 'banner_position' ) THEN ALTER TABLE users ADD COLUMN banner_position INTEGER DEFAULT 50; END IF; END $$; -- Add banner_zoom column to users table (100-200 representing zoom percentage) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'users' AND column_name = 'banner_zoom' ) THEN ALTER TABLE users ADD COLUMN banner_zoom INTEGER DEFAULT 100; END IF; END $$; -- Add banner_position_x column to users table (0-100 representing X percentage for object-position) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'users' AND column_name = 'banner_position_x' ) THEN ALTER TABLE users ADD COLUMN banner_position_x INTEGER DEFAULT 50; END IF; END $$; -- Create index for is_restreamer CREATE INDEX IF NOT EXISTS idx_users_is_restreamer ON users(is_restreamer); -- Restream destinations table (max 2 per realm enforced by application) CREATE TABLE IF NOT EXISTS restream_destinations ( id BIGSERIAL PRIMARY KEY, realm_id BIGINT NOT NULL REFERENCES realms(id) ON DELETE CASCADE, name VARCHAR(100) NOT NULL, rtmp_url VARCHAR(500) NOT NULL, stream_key VARCHAR(500) NOT NULL, enabled BOOLEAN DEFAULT true, is_connected BOOLEAN DEFAULT false, last_error TEXT, last_connected_at TIMESTAMP WITH TIME ZONE, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Create indexes for restream_destinations CREATE INDEX IF NOT EXISTS idx_restream_destinations_realm_id ON restream_destinations(realm_id); CREATE INDEX IF NOT EXISTS idx_restream_destinations_enabled ON restream_destinations(enabled); -- Trigger for restream_destinations updated_at DROP TRIGGER IF EXISTS update_restream_destinations_updated_at ON restream_destinations; CREATE TRIGGER update_restream_destinations_updated_at BEFORE UPDATE ON restream_destinations FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- Add is_bot column to users table (for Bot role - allows API key generation) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'users' AND column_name = 'is_bot' ) THEN ALTER TABLE users ADD COLUMN is_bot BOOLEAN DEFAULT false; END IF; END $$; -- Create index for is_bot CREATE INDEX IF NOT EXISTS idx_users_is_bot ON users(is_bot); -- Bot API keys table (for chatbot authentication) CREATE TABLE IF NOT EXISTS bot_api_keys ( id BIGSERIAL PRIMARY KEY, user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE, api_key VARCHAR(64) UNIQUE NOT NULL, name VARCHAR(100) NOT NULL CHECK (name ~ '^[a-zA-Z0-9_-]+$'), scopes TEXT DEFAULT 'chat:rw', is_active BOOLEAN DEFAULT true, last_used_at TIMESTAMP WITH TIME ZONE, expires_at TIMESTAMP WITH TIME ZONE DEFAULT (CURRENT_TIMESTAMP + INTERVAL '1 year'), created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Add expires_at column if it doesn't exist (for existing databases) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'bot_api_keys' AND column_name = 'expires_at' ) THEN ALTER TABLE bot_api_keys ADD COLUMN expires_at TIMESTAMP WITH TIME ZONE DEFAULT (CURRENT_TIMESTAMP + INTERVAL '1 year'); END IF; END $$; -- Add scopes column if it doesn't exist (for existing databases) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'bot_api_keys' AND column_name = 'scopes' ) THEN ALTER TABLE bot_api_keys ADD COLUMN scopes TEXT DEFAULT 'chat:rw'; END IF; END $$; -- Update existing 'chat:write' scopes to 'chat:rw' (migration for existing keys) UPDATE bot_api_keys SET scopes = 'chat:rw' WHERE scopes = 'chat:write'; -- Add name format CHECK constraint if it doesn't exist (for existing databases) DO $$ BEGIN ALTER TABLE bot_api_keys DROP CONSTRAINT IF EXISTS bot_api_keys_name_check; ALTER TABLE bot_api_keys ADD CONSTRAINT bot_api_keys_name_check CHECK (name ~ '^[a-zA-Z0-9_-]+$'); EXCEPTION WHEN others THEN NULL; END $$; -- Create indexes for bot_api_keys CREATE INDEX IF NOT EXISTS idx_bot_api_keys_api_key ON bot_api_keys(api_key) WHERE is_active = true; CREATE INDEX IF NOT EXISTS idx_bot_api_keys_user_id ON bot_api_keys(user_id); -- Honk sounds table (for @mention notification sounds) CREATE TABLE IF NOT EXISTS honk_sounds ( id BIGSERIAL PRIMARY KEY, name VARCHAR(100) NOT NULL, file_path VARCHAR(255) NOT NULL, is_active BOOLEAN DEFAULT false, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Create honk sounds indexes CREATE INDEX IF NOT EXISTS idx_honk_sounds_active ON honk_sounds(is_active); -- Ensure only one honk sound can be active at a time CREATE OR REPLACE FUNCTION ensure_single_active_honk() RETURNS TRIGGER AS $$ BEGIN IF NEW.is_active = true THEN UPDATE honk_sounds SET is_active = false WHERE id != NEW.id AND is_active = true; END IF; RETURN NEW; END; $$ language 'plpgsql'; DROP TRIGGER IF EXISTS single_active_honk ON honk_sounds; CREATE TRIGGER single_active_honk AFTER INSERT OR UPDATE ON honk_sounds FOR EACH ROW EXECUTE FUNCTION ensure_single_active_honk(); -- Add is_sticker_creator column to users table DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'users' AND column_name = 'is_sticker_creator' ) THEN ALTER TABLE users ADD COLUMN is_sticker_creator BOOLEAN DEFAULT false; END IF; END $$; -- Create index for is_sticker_creator CREATE INDEX IF NOT EXISTS idx_users_is_sticker_creator ON users(is_sticker_creator); -- Sticker submissions table (for sticker creator approval workflow) CREATE TABLE IF NOT EXISTS sticker_submissions ( id BIGSERIAL PRIMARY KEY, name VARCHAR(50) NOT NULL, file_path VARCHAR(255) NOT NULL, submitted_by BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE, status VARCHAR(20) DEFAULT 'pending' CHECK (status IN ('pending', 'approved', 'denied')), reviewed_by BIGINT REFERENCES users(id) ON DELETE SET NULL, reviewed_at TIMESTAMP WITH TIME ZONE, denial_reason TEXT, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Create sticker submissions indexes CREATE INDEX IF NOT EXISTS idx_sticker_submissions_status ON sticker_submissions(status); CREATE INDEX IF NOT EXISTS idx_sticker_submissions_submitted_by ON sticker_submissions(submitted_by); CREATE INDEX IF NOT EXISTS idx_sticker_submissions_created_at ON sticker_submissions(created_at DESC); -- Add graffiti_url column to users table (88x33 pixel art signature GIF) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'users' AND column_name = 'graffiti_url' ) THEN ALTER TABLE users ADD COLUMN graffiti_url VARCHAR(255); END IF; END $$; -- Add is_uploader column to users table (for video uploads) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'users' AND column_name = 'is_uploader' ) THEN ALTER TABLE users ADD COLUMN is_uploader BOOLEAN DEFAULT false; END IF; END $$; -- Create index for is_uploader CREATE INDEX IF NOT EXISTS idx_users_is_uploader ON users(is_uploader); -- Video uploads table CREATE TABLE IF NOT EXISTS videos ( id BIGSERIAL PRIMARY KEY, user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE, realm_id BIGINT NOT NULL REFERENCES realms(id) ON DELETE CASCADE, title VARCHAR(255) NOT NULL, description TEXT DEFAULT '', file_path VARCHAR(500) NOT NULL, thumbnail_path VARCHAR(500), preview_path VARCHAR(500), duration_seconds INTEGER DEFAULT 0, file_size_bytes BIGINT DEFAULT 0, width INTEGER, height INTEGER, status VARCHAR(20) DEFAULT 'processing' CHECK (status IN ('processing', 'ready', 'failed', 'deleted')), view_count INTEGER DEFAULT 0, is_public BOOLEAN DEFAULT true, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Add preview_path column if it doesn't exist (for existing databases) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'videos' AND column_name = 'preview_path' ) THEN ALTER TABLE videos ADD COLUMN preview_path VARCHAR(500); END IF; END $$; -- Add bitrate column to videos table if it doesn't exist DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'videos' AND column_name = 'bitrate' ) THEN ALTER TABLE videos ADD COLUMN bitrate INTEGER; END IF; END $$; -- Add video_codec column to videos table if it doesn't exist DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'videos' AND column_name = 'video_codec' ) THEN ALTER TABLE videos ADD COLUMN video_codec VARCHAR(50); END IF; END $$; -- Add audio_codec column to videos table if it doesn't exist DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'videos' AND column_name = 'audio_codec' ) THEN ALTER TABLE videos ADD COLUMN audio_codec VARCHAR(50); END IF; END $$; -- Create indexes for videos CREATE INDEX IF NOT EXISTS idx_videos_user_id ON videos(user_id); CREATE INDEX IF NOT EXISTS idx_videos_realm_id ON videos(realm_id); CREATE INDEX IF NOT EXISTS idx_videos_status ON videos(status); CREATE INDEX IF NOT EXISTS idx_videos_is_public ON videos(is_public); CREATE INDEX IF NOT EXISTS idx_videos_created_at ON videos(created_at DESC); CREATE INDEX IF NOT EXISTS idx_videos_view_count ON videos(view_count DESC); CREATE INDEX IF NOT EXISTS idx_videos_public_ready ON videos(is_public, status) WHERE is_public = true AND status = 'ready'; -- Trigger for videos updated_at DROP TRIGGER IF EXISTS update_videos_updated_at ON videos; CREATE TRIGGER update_videos_updated_at BEFORE UPDATE ON videos FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- Site settings table for customization (logo, title, etc.) CREATE TABLE IF NOT EXISTS site_settings ( id SERIAL PRIMARY KEY, setting_key VARCHAR(100) UNIQUE NOT NULL, setting_value TEXT, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Insert default site settings INSERT INTO site_settings (setting_key, setting_value) VALUES ('site_title', 'Stream'), ('logo_path', ''), ('logo_display_mode', 'text'), -- 'text', 'image', 'both' ('announcement_enabled', 'false'), ('announcement_text', '') ON CONFLICT (setting_key) DO NOTHING; -- Trigger for site_settings updated_at DROP TRIGGER IF EXISTS update_site_settings_updated_at ON site_settings; CREATE TRIGGER update_site_settings_updated_at BEFORE UPDATE ON site_settings FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- SSL/TLS Certificate Settings (singleton table for Let's Encrypt management) CREATE TABLE IF NOT EXISTS ssl_settings ( id INTEGER PRIMARY KEY DEFAULT 1 CHECK (id = 1), domain VARCHAR(255), acme_email VARCHAR(255), certificate_status VARCHAR(20) DEFAULT 'none' CHECK (certificate_status IN ('none', 'pending', 'active', 'expired', 'error')), certificate_expiry TIMESTAMP WITH TIME ZONE, last_renewal_attempt TIMESTAMP WITH TIME ZONE, last_renewal_error TEXT, auto_renewal_enabled BOOLEAN DEFAULT true, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Insert default SSL settings row INSERT INTO ssl_settings (id, domain, certificate_status) VALUES (1, '', 'none') ON CONFLICT (id) DO NOTHING; -- Trigger for ssl_settings updated_at DROP TRIGGER IF EXISTS update_ssl_settings_updated_at ON ssl_settings; CREATE TRIGGER update_ssl_settings_updated_at BEFORE UPDATE ON ssl_settings FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- Add offline_image_url column to realms table (for stream realms to display when offline) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'realms' AND column_name = 'offline_image_url' ) THEN ALTER TABLE realms ADD COLUMN offline_image_url VARCHAR(500); END IF; END $$; -- Add title_color column to realms table (hex color for realm title display) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'realms' AND column_name = 'title_color' ) THEN ALTER TABLE realms ADD COLUMN title_color VARCHAR(7) DEFAULT '#ffffff'; END IF; END $$; -- Update realm_type CHECK constraint to include 'audio' DO $$ BEGIN -- Drop the old constraint if it exists ALTER TABLE realms DROP CONSTRAINT IF EXISTS realms_realm_type_check; -- Add the new constraint with 'audio' type ALTER TABLE realms ADD CONSTRAINT realms_realm_type_check CHECK (realm_type IN ('stream', 'video', 'audio')); EXCEPTION WHEN others THEN NULL; END $$; -- Audio files table (for audio realms) CREATE TABLE IF NOT EXISTS audio_files ( id BIGSERIAL PRIMARY KEY, user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE, realm_id BIGINT NOT NULL REFERENCES realms(id) ON DELETE CASCADE, title VARCHAR(255) NOT NULL, description TEXT DEFAULT '', file_path VARCHAR(500) NOT NULL, thumbnail_path VARCHAR(500), -- Optional cover art duration_seconds INTEGER DEFAULT 0, file_size_bytes BIGINT DEFAULT 0, format VARCHAR(20), -- mp3, wav, flac, ogg, aac bitrate INTEGER, -- kbps status VARCHAR(20) DEFAULT 'processing' CHECK (status IN ('processing', 'ready', 'failed', 'deleted')), play_count INTEGER DEFAULT 0, is_public BOOLEAN DEFAULT true, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Create indexes for audio_files CREATE INDEX IF NOT EXISTS idx_audio_files_user_id ON audio_files(user_id); CREATE INDEX IF NOT EXISTS idx_audio_files_realm_id ON audio_files(realm_id); CREATE INDEX IF NOT EXISTS idx_audio_files_status ON audio_files(status); CREATE INDEX IF NOT EXISTS idx_audio_files_is_public ON audio_files(is_public); CREATE INDEX IF NOT EXISTS idx_audio_files_created_at ON audio_files(created_at DESC); CREATE INDEX IF NOT EXISTS idx_audio_files_play_count ON audio_files(play_count DESC); CREATE INDEX IF NOT EXISTS idx_audio_files_public_ready ON audio_files(is_public, status) WHERE is_public = true AND status = 'ready'; -- Trigger for audio_files updated_at DROP TRIGGER IF EXISTS update_audio_files_updated_at ON audio_files; CREATE TRIGGER update_audio_files_updated_at BEFORE UPDATE ON audio_files FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- Update realm_type CHECK constraint to include 'ebook' DO $$ BEGIN -- Drop the old constraint if it exists ALTER TABLE realms DROP CONSTRAINT IF EXISTS realms_realm_type_check; -- Add the new constraint with 'ebook' type ALTER TABLE realms ADD CONSTRAINT realms_realm_type_check CHECK (realm_type IN ('stream', 'video', 'audio', 'ebook')); EXCEPTION WHEN others THEN NULL; END $$; -- Ebook files table (for ebook realms - EPUB only) CREATE TABLE IF NOT EXISTS ebooks ( id BIGSERIAL PRIMARY KEY, user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE, realm_id BIGINT NOT NULL REFERENCES realms(id) ON DELETE CASCADE, title VARCHAR(255) NOT NULL, description TEXT DEFAULT '', file_path VARCHAR(500) NOT NULL, cover_path VARCHAR(500), -- Cover image (extracted from EPUB or user-uploaded) file_size_bytes BIGINT DEFAULT 0, chapter_count INTEGER, -- Extracted from TOC status VARCHAR(20) DEFAULT 'processing' CHECK (status IN ('processing', 'ready', 'failed', 'deleted')), read_count INTEGER DEFAULT 0, is_public BOOLEAN DEFAULT true, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Create indexes for ebooks CREATE INDEX IF NOT EXISTS idx_ebooks_user_id ON ebooks(user_id); CREATE INDEX IF NOT EXISTS idx_ebooks_realm_id ON ebooks(realm_id); CREATE INDEX IF NOT EXISTS idx_ebooks_status ON ebooks(status); CREATE INDEX IF NOT EXISTS idx_ebooks_is_public ON ebooks(is_public); CREATE INDEX IF NOT EXISTS idx_ebooks_created_at ON ebooks(created_at DESC); CREATE INDEX IF NOT EXISTS idx_ebooks_read_count ON ebooks(read_count DESC); CREATE INDEX IF NOT EXISTS idx_ebooks_public_ready ON ebooks(is_public, status) WHERE is_public = true AND status = 'ready'; -- Trigger for ebooks updated_at DROP TRIGGER IF EXISTS update_ebooks_updated_at ON ebooks; CREATE TRIGGER update_ebooks_updated_at BEFORE UPDATE ON ebooks FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- Add is_texter column to users table (for forum creation) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'users' AND column_name = 'is_texter' ) THEN ALTER TABLE users ADD COLUMN is_texter BOOLEAN DEFAULT false; END IF; END $$; -- Create index for is_texter CREATE INDEX IF NOT EXISTS idx_users_is_texter ON users(is_texter); -- Forums table (owned by texters) CREATE TABLE IF NOT EXISTS forums ( id BIGSERIAL PRIMARY KEY, user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE, name VARCHAR(100) NOT NULL, slug VARCHAR(100) UNIQUE NOT NULL, description TEXT DEFAULT '', banner_url VARCHAR(255) DEFAULT '', banner_position INTEGER DEFAULT 50, banner_position_x INTEGER DEFAULT 50, banner_zoom INTEGER DEFAULT 100, title_color VARCHAR(7) DEFAULT '#ffffff', is_active BOOLEAN DEFAULT true, thread_count INTEGER DEFAULT 0, post_count INTEGER DEFAULT 0, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Add banner columns if they don't exist (for existing databases) DO $$ BEGIN IF NOT EXISTS (SELECT 1 FROM information_schema.columns WHERE table_name = 'forums' AND column_name = 'banner_url') THEN ALTER TABLE forums ADD COLUMN banner_url VARCHAR(255) DEFAULT ''; END IF; IF NOT EXISTS (SELECT 1 FROM information_schema.columns WHERE table_name = 'forums' AND column_name = 'banner_position') THEN ALTER TABLE forums ADD COLUMN banner_position INTEGER DEFAULT 50; END IF; IF NOT EXISTS (SELECT 1 FROM information_schema.columns WHERE table_name = 'forums' AND column_name = 'banner_position_x') THEN ALTER TABLE forums ADD COLUMN banner_position_x INTEGER DEFAULT 50; END IF; IF NOT EXISTS (SELECT 1 FROM information_schema.columns WHERE table_name = 'forums' AND column_name = 'banner_zoom') THEN ALTER TABLE forums ADD COLUMN banner_zoom INTEGER DEFAULT 100; END IF; IF NOT EXISTS (SELECT 1 FROM information_schema.columns WHERE table_name = 'forums' AND column_name = 'title_color') THEN ALTER TABLE forums ADD COLUMN title_color VARCHAR(7) DEFAULT '#ffffff'; END IF; END $$; -- Create indexes for forums CREATE INDEX IF NOT EXISTS idx_forums_user_id ON forums(user_id); CREATE INDEX IF NOT EXISTS idx_forums_slug ON forums(slug); CREATE INDEX IF NOT EXISTS idx_forums_is_active ON forums(is_active); CREATE INDEX IF NOT EXISTS idx_forums_created_at ON forums(created_at DESC); -- Trigger for forums updated_at DROP TRIGGER IF EXISTS update_forums_updated_at ON forums; CREATE TRIGGER update_forums_updated_at BEFORE UPDATE ON forums FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- Forum threads table CREATE TABLE IF NOT EXISTS forum_threads ( id BIGSERIAL PRIMARY KEY, forum_id BIGINT NOT NULL REFERENCES forums(id) ON DELETE CASCADE, user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE, title VARCHAR(255) NOT NULL, content TEXT NOT NULL, is_pinned BOOLEAN DEFAULT false, is_locked BOOLEAN DEFAULT false, post_count INTEGER DEFAULT 0, last_post_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, last_post_user_id BIGINT REFERENCES users(id) ON DELETE SET NULL, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Create indexes for forum_threads CREATE INDEX IF NOT EXISTS idx_forum_threads_forum_id ON forum_threads(forum_id); CREATE INDEX IF NOT EXISTS idx_forum_threads_user_id ON forum_threads(user_id); CREATE INDEX IF NOT EXISTS idx_forum_threads_is_pinned ON forum_threads(is_pinned); CREATE INDEX IF NOT EXISTS idx_forum_threads_last_post_at ON forum_threads(last_post_at DESC); CREATE INDEX IF NOT EXISTS idx_forum_threads_created_at ON forum_threads(created_at DESC); -- Trigger for forum_threads updated_at DROP TRIGGER IF EXISTS update_forum_threads_updated_at ON forum_threads; CREATE TRIGGER update_forum_threads_updated_at BEFORE UPDATE ON forum_threads FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- Forum posts table (replies to threads) CREATE TABLE IF NOT EXISTS forum_posts ( id BIGSERIAL PRIMARY KEY, thread_id BIGINT NOT NULL REFERENCES forum_threads(id) ON DELETE CASCADE, user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE, content TEXT NOT NULL, is_edited BOOLEAN DEFAULT false, edited_at TIMESTAMP WITH TIME ZONE, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Create indexes for forum_posts CREATE INDEX IF NOT EXISTS idx_forum_posts_thread_id ON forum_posts(thread_id); CREATE INDEX IF NOT EXISTS idx_forum_posts_user_id ON forum_posts(user_id); CREATE INDEX IF NOT EXISTS idx_forum_posts_created_at ON forum_posts(created_at); -- Forum bans table (per-forum user bans, managed by forum owner or admin) CREATE TABLE IF NOT EXISTS forum_bans ( id BIGSERIAL PRIMARY KEY, forum_id BIGINT NOT NULL REFERENCES forums(id) ON DELETE CASCADE, user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE, banned_by BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE, reason TEXT DEFAULT '', expires_at TIMESTAMP WITH TIME ZONE, -- NULL = permanent created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, UNIQUE(forum_id, user_id) ); -- Create indexes for forum_bans CREATE INDEX IF NOT EXISTS idx_forum_bans_forum_id ON forum_bans(forum_id); CREATE INDEX IF NOT EXISTS idx_forum_bans_user_id ON forum_bans(user_id); CREATE INDEX IF NOT EXISTS idx_forum_bans_expires_at ON forum_bans(expires_at); -- ============================================ -- WATCH ROOMS (YouTube Sync - CyTube style) -- ============================================ -- Update realm_type CHECK constraint to include 'watch' DO $$ BEGIN ALTER TABLE realms DROP CONSTRAINT IF EXISTS realms_realm_type_check; ALTER TABLE realms ADD CONSTRAINT realms_realm_type_check CHECK (realm_type IN ('stream', 'video', 'audio', 'ebook', 'watch')); EXCEPTION WHEN others THEN NULL; END $$; -- Add playlist control columns to realms (for watch rooms) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'realms' AND column_name = 'playlist_control_mode' ) THEN ALTER TABLE realms ADD COLUMN playlist_control_mode VARCHAR(20) DEFAULT 'owner'; END IF; END $$; DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'realms' AND column_name = 'playlist_whitelist' ) THEN ALTER TABLE realms ADD COLUMN playlist_whitelist TEXT DEFAULT '[]'; END IF; END $$; -- Watch playlist table (queue of YouTube videos for watch rooms) -- Note: position column is deprecated - ordering now uses created_at timestamp CREATE TABLE IF NOT EXISTS watch_playlist ( id BIGSERIAL PRIMARY KEY, realm_id BIGINT NOT NULL REFERENCES realms(id) ON DELETE CASCADE, youtube_video_id VARCHAR(20) NOT NULL, title VARCHAR(255) NOT NULL, duration_seconds INTEGER NOT NULL, thumbnail_url VARCHAR(500), added_by BIGINT REFERENCES users(id) ON DELETE SET NULL, added_by_username VARCHAR(255) NOT NULL, position INTEGER DEFAULT 0, status VARCHAR(20) DEFAULT 'queued' CHECK (status IN ('queued', 'playing', 'played', 'skipped')), started_at TIMESTAMP WITH TIME ZONE, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Migration: Allow NULL for position column (ordering now uses created_at) DO $$ BEGIN ALTER TABLE watch_playlist ALTER COLUMN position DROP NOT NULL; ALTER TABLE watch_playlist ALTER COLUMN position SET DEFAULT 0; EXCEPTION WHEN others THEN NULL; END $$; -- Create indexes for watch_playlist CREATE INDEX IF NOT EXISTS idx_watch_playlist_realm_id ON watch_playlist(realm_id); CREATE INDEX IF NOT EXISTS idx_watch_playlist_position ON watch_playlist(realm_id, position); CREATE INDEX IF NOT EXISTS idx_watch_playlist_status ON watch_playlist(status); -- Composite index for efficient playlist ordering by created_at (used instead of position) CREATE INDEX IF NOT EXISTS idx_watch_playlist_realm_created ON watch_playlist(realm_id, created_at ASC); -- Watch room state table (current playback state for sync) CREATE TABLE IF NOT EXISTS watch_room_state ( realm_id BIGINT PRIMARY KEY REFERENCES realms(id) ON DELETE CASCADE, current_video_id BIGINT REFERENCES watch_playlist(id) ON DELETE SET NULL, playback_state VARCHAR(20) DEFAULT 'paused' CHECK (playback_state IN ('playing', 'paused', 'ended')), current_time_seconds FLOAT DEFAULT 0, last_sync_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, viewer_count INTEGER DEFAULT 0, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Trigger for watch_room_state updated_at DROP TRIGGER IF EXISTS update_watch_room_state_updated_at ON watch_room_state; CREATE TRIGGER update_watch_room_state_updated_at BEFORE UPDATE ON watch_room_state FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- Add guest_fingerprint column to watch_playlist for tracking guest video limits DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'watch_playlist' AND column_name = 'guest_fingerprint' ) THEN ALTER TABLE watch_playlist ADD COLUMN guest_fingerprint VARCHAR(100); END IF; END $$; -- Index for efficient guest video count queries CREATE INDEX IF NOT EXISTS idx_watch_playlist_guest_fingerprint ON watch_playlist(guest_fingerprint) WHERE guest_fingerprint IS NOT NULL; -- Add is_locked column to watch_playlist for locking videos to loop forever DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'watch_playlist' AND column_name = 'is_locked' ) THEN ALTER TABLE watch_playlist ADD COLUMN is_locked BOOLEAN DEFAULT FALSE; END IF; END $$; -- Index for efficient locked video queries CREATE INDEX IF NOT EXISTS idx_watch_playlist_is_locked ON watch_playlist(realm_id, is_locked) WHERE is_locked = TRUE; -- Add is_watch_creator column to users table (for watch room creation - separate from uploader role) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'users' AND column_name = 'is_watch_creator' ) THEN ALTER TABLE users ADD COLUMN is_watch_creator BOOLEAN DEFAULT false; END IF; END $$; -- Create index for is_watch_creator CREATE INDEX IF NOT EXISTS idx_users_is_watch_creator ON users(is_watch_creator); -- Add is_disabled column to users table (disabled users cannot login) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'users' AND column_name = 'is_disabled' ) THEN ALTER TABLE users ADD COLUMN is_disabled BOOLEAN DEFAULT false; END IF; END $$; -- Create index for is_disabled CREATE INDEX IF NOT EXISTS idx_users_is_disabled ON users(is_disabled); -- Add censored_words setting to site_settings INSERT INTO site_settings (setting_key, setting_value) VALUES ('censored_words', '') ON CONFLICT (setting_key) DO NOTHING; -- Add original_creator_username column to realms table (preserves creator info when user is deleted) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'realms' AND column_name = 'original_creator_username' ) THEN ALTER TABLE realms ADD COLUMN original_creator_username VARCHAR(255); END IF; END $$; -- ============================================ -- ÜBERCOIN VIRTUAL CURRENCY SYSTEM -- ============================================ -- Add ubercoin_balance column to users table (3 decimal places, default 612.000) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'users' AND column_name = 'ubercoin_balance' ) THEN ALTER TABLE users ADD COLUMN ubercoin_balance NUMERIC(18,3) DEFAULT 612.000; END IF; END $$; -- Create index for ubercoin_balance (for leaderboards, etc.) CREATE INDEX IF NOT EXISTS idx_users_ubercoin_balance ON users(ubercoin_balance DESC); -- Übercoin treasury table (singleton - tracks burned coins and redistribution) CREATE TABLE IF NOT EXISTS ubercoin_treasury ( id INTEGER PRIMARY KEY DEFAULT 1 CHECK (id = 1), balance NUMERIC(18,3) DEFAULT 0.000, total_destroyed NUMERIC(18,3) DEFAULT 0.000, last_growth_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, last_distribution_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Insert default treasury row (only one row can exist due to CHECK constraint) INSERT INTO ubercoin_treasury (id, balance, total_destroyed) VALUES (1, 0.000, 0.000) ON CONFLICT (id) DO NOTHING; -- Trigger for ubercoin_treasury updated_at DROP TRIGGER IF EXISTS update_ubercoin_treasury_updated_at ON ubercoin_treasury; CREATE TRIGGER update_ubercoin_treasury_updated_at BEFORE UPDATE ON ubercoin_treasury FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- ============================================ -- DEFAULT GUEST AVATARS -- ============================================ -- Default avatars table (for random guest avatar assignment) CREATE TABLE IF NOT EXISTS default_avatars ( id BIGSERIAL PRIMARY KEY, file_path VARCHAR(500) NOT NULL, is_active BOOLEAN DEFAULT true, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Create indexes for default_avatars CREATE INDEX IF NOT EXISTS idx_default_avatars_active ON default_avatars(is_active) WHERE is_active = true; -- ============================================ -- CHAT MODERATION SYSTEM ENHANCEMENTS -- ============================================ -- Add is_moderator column to users table (site-wide moderator role) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'users' AND column_name = 'is_moderator' ) THEN ALTER TABLE users ADD COLUMN is_moderator BOOLEAN DEFAULT false; END IF; END $$; -- Create index for is_moderator CREATE INDEX IF NOT EXISTS idx_users_is_moderator ON users(is_moderator); -- Realm bans table (per-realm bans for users and guests) CREATE TABLE IF NOT EXISTS realm_bans ( id BIGSERIAL PRIMARY KEY, realm_id BIGINT NOT NULL REFERENCES realms(id) ON DELETE CASCADE, user_id BIGINT REFERENCES users(id) ON DELETE CASCADE, -- NULL for guest bans guest_fingerprint VARCHAR(64), -- For guest bans (NULL for user bans) banned_by BIGINT NOT NULL REFERENCES users(id), reason TEXT DEFAULT '', banned_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, CONSTRAINT realm_bans_target_check CHECK ( (user_id IS NOT NULL AND guest_fingerprint IS NULL) OR (user_id IS NULL AND guest_fingerprint IS NOT NULL) ) ); -- Create unique constraints to prevent duplicate bans CREATE UNIQUE INDEX IF NOT EXISTS idx_realm_bans_user ON realm_bans(realm_id, user_id) WHERE user_id IS NOT NULL; CREATE UNIQUE INDEX IF NOT EXISTS idx_realm_bans_fingerprint ON realm_bans(realm_id, guest_fingerprint) WHERE guest_fingerprint IS NOT NULL; -- Create indexes for efficient lookups CREATE INDEX IF NOT EXISTS idx_realm_bans_realm_id ON realm_bans(realm_id); CREATE INDEX IF NOT EXISTS idx_realm_bans_user_id ON realm_bans(user_id) WHERE user_id IS NOT NULL; CREATE INDEX IF NOT EXISTS idx_realm_bans_guest_fingerprint ON realm_bans(guest_fingerprint) WHERE guest_fingerprint IS NOT NULL; -- ============================================ -- SECURITY FIX #15: Remove UNIQUE constraint on user_color -- (Prevents user enumeration attack via color collision errors) -- ============================================ DO $$ BEGIN ALTER TABLE users DROP CONSTRAINT IF EXISTS users_user_color_key; EXCEPTION WHEN others THEN NULL; END $$; -- ============================================ -- SECURITY FIX #19: Add CHECK constraint for password_hash/is_pgp_only -- (Ensures data integrity - password required for non-PGP accounts) -- ============================================ DO $$ BEGIN ALTER TABLE users DROP CONSTRAINT IF EXISTS users_password_pgp_check; ALTER TABLE users ADD CONSTRAINT users_password_pgp_check CHECK ( (is_pgp_only = true) OR (is_pgp_only = false AND password_hash IS NOT NULL) OR (is_pgp_only IS NULL AND password_hash IS NOT NULL) ); EXCEPTION WHEN others THEN NULL; END $$; -- ============================================ -- SECURITY FIX #10: Add token_version for JWT revocation -- (Allows invalidating all tokens on password change) -- ============================================ DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'users' AND column_name = 'token_version' ) THEN ALTER TABLE users ADD COLUMN token_version INTEGER DEFAULT 1; END IF; END $$; -- Create index for token_version lookups CREATE INDEX IF NOT EXISTS idx_users_token_version ON users(id, token_version); -- ============================================ -- STICKER USAGE TRACKING -- ============================================ -- Add usage_count column to stickers table for tracking usage statistics DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'stickers' AND column_name = 'usage_count' ) THEN ALTER TABLE stickers ADD COLUMN usage_count BIGINT DEFAULT 0; END IF; END $$; -- Create index for efficient top stickers query CREATE INDEX IF NOT EXISTS idx_stickers_usage_count ON stickers(usage_count DESC) WHERE is_active = true; -- ============================================ -- REFERRAL CODE SYSTEM -- ============================================ -- Add referral_system_enabled column to chat_settings (for existing databases) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'chat_settings' AND column_name = 'referral_system_enabled' ) THEN ALTER TABLE chat_settings ADD COLUMN referral_system_enabled BOOLEAN DEFAULT false; END IF; END $$; -- Referral codes table (single-use registration codes purchased with ubercoin) CREATE TABLE IF NOT EXISTS referral_codes ( id BIGSERIAL PRIMARY KEY, owner_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE, code VARCHAR(12) UNIQUE NOT NULL, is_used BOOLEAN DEFAULT false, used_by BIGINT REFERENCES users(id) ON DELETE SET NULL, used_at TIMESTAMP WITH TIME ZONE, created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Create indexes for referral_codes CREATE INDEX IF NOT EXISTS idx_referral_codes_owner_id ON referral_codes(owner_id); CREATE INDEX IF NOT EXISTS idx_referral_codes_code ON referral_codes(code) WHERE is_used = false; CREATE INDEX IF NOT EXISTS idx_referral_codes_is_used ON referral_codes(is_used); CREATE INDEX IF NOT EXISTS idx_referral_codes_used_by ON referral_codes(used_by) WHERE used_by IS NOT NULL; -- ============================================ -- PENDING UBERBAN SYSTEM -- (Deferred fingerprint ban - applies on next activity) -- ============================================ -- Add pending_uberban column to users table (marks user for uberban on next login/connect) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'users' AND column_name = 'pending_uberban' ) THEN ALTER TABLE users ADD COLUMN pending_uberban BOOLEAN DEFAULT false; END IF; END $$; -- Add pending_uberban_at column (when the uberban was requested) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'users' AND column_name = 'pending_uberban_at' ) THEN ALTER TABLE users ADD COLUMN pending_uberban_at TIMESTAMP WITH TIME ZONE; END IF; END $$; -- Create index for pending_uberban lookups CREATE INDEX IF NOT EXISTS idx_users_pending_uberban ON users(pending_uberban) WHERE pending_uberban = true; -- ============================================ -- REFRESH TOKEN FAMILIES (JWT Token Rotation) -- ============================================ -- Refresh token families table for secure token rotation -- Each login creates a new "family" - if an old token is reused, the whole family is revoked CREATE TABLE IF NOT EXISTS refresh_token_families ( id BIGSERIAL PRIMARY KEY, user_id BIGINT NOT NULL REFERENCES users(id) ON DELETE CASCADE, family_id UUID NOT NULL UNIQUE, current_token_hash VARCHAR(64) NOT NULL, -- SHA256 of current valid refresh token created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP, expires_at TIMESTAMP WITH TIME ZONE NOT NULL, revoked BOOLEAN DEFAULT FALSE, revoked_at TIMESTAMP WITH TIME ZONE, last_used_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP ); -- Create indexes for refresh_token_families CREATE INDEX IF NOT EXISTS idx_refresh_families_user_id ON refresh_token_families(user_id); CREATE INDEX IF NOT EXISTS idx_refresh_families_family_id ON refresh_token_families(family_id); CREATE INDEX IF NOT EXISTS idx_refresh_families_active ON refresh_token_families(user_id, revoked) WHERE revoked = FALSE; CREATE INDEX IF NOT EXISTS idx_refresh_families_expires ON refresh_token_families(expires_at) WHERE revoked = FALSE; -- ============================================ -- SCREENSAVER SETTINGS -- ============================================ -- Add screensaver_enabled column to users table (default disabled) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'users' AND column_name = 'screensaver_enabled' ) THEN ALTER TABLE users ADD COLUMN screensaver_enabled BOOLEAN DEFAULT false; END IF; END $$; -- Add screensaver_timeout_minutes column to users table (default 5 minutes, range 1-30) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'users' AND column_name = 'screensaver_timeout_minutes' ) THEN ALTER TABLE users ADD COLUMN screensaver_timeout_minutes INTEGER DEFAULT 5; END IF; END $$; -- ============================================ -- LIVE STREAM DURATION TRACKING -- ============================================ -- Add live_started_at column to realms table (tracks when stream went live for duration display) DO $$ BEGIN IF NOT EXISTS ( SELECT 1 FROM information_schema.columns WHERE table_name = 'realms' AND column_name = 'live_started_at' ) THEN ALTER TABLE realms ADD COLUMN live_started_at TIMESTAMP WITH TIME ZONE; END IF; END $$;