-- Consolidated migrations for Telegram Tinder Bot -- Create extension for UUID if not exists CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; CREATE EXTENSION IF NOT EXISTS "pgcrypto"; ---------------------------------------------- -- Core Tables ---------------------------------------------- -- Users table CREATE TABLE IF NOT EXISTS users ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), telegram_id BIGINT UNIQUE NOT NULL, username VARCHAR(255), first_name VARCHAR(255), last_name VARCHAR(255), language_code VARCHAR(10) DEFAULT 'ru', is_active BOOLEAN DEFAULT TRUE, created_at TIMESTAMP DEFAULT NOW(), last_active_at TIMESTAMP DEFAULT NOW(), premium BOOLEAN DEFAULT FALSE, state VARCHAR(255), state_data JSONB DEFAULT '{}'::jsonb ); -- Profiles table CREATE TABLE IF NOT EXISTS profiles ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID REFERENCES users(id) ON DELETE CASCADE, name VARCHAR(255) NOT NULL, age INTEGER NOT NULL CHECK (age >= 18 AND age <= 100), gender VARCHAR(10) NOT NULL CHECK (gender IN ('male', 'female', 'other')), interested_in VARCHAR(10) NOT NULL CHECK (interested_in IN ('male', 'female', 'both')), bio TEXT, photos JSONB DEFAULT '[]', interests JSONB DEFAULT '[]', city VARCHAR(255), education VARCHAR(255), job VARCHAR(255), height INTEGER, location_lat DECIMAL(10, 8), location_lon DECIMAL(11, 8), search_min_age INTEGER DEFAULT 18, search_max_age INTEGER DEFAULT 50, search_max_distance INTEGER DEFAULT 50, is_verified BOOLEAN DEFAULT FALSE, is_visible BOOLEAN DEFAULT TRUE, created_at TIMESTAMP DEFAULT NOW(), updated_at TIMESTAMP DEFAULT NOW(), religion VARCHAR(255), dating_goal VARCHAR(50), smoking VARCHAR(20), drinking VARCHAR(20), has_kids BOOLEAN DEFAULT FALSE ); -- Swipes table CREATE TABLE IF NOT EXISTS swipes ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID REFERENCES users(id) ON DELETE CASCADE, target_user_id UUID REFERENCES users(id) ON DELETE CASCADE, type VARCHAR(20) NOT NULL CHECK (type IN ('like', 'pass', 'superlike')), created_at TIMESTAMP DEFAULT NOW(), is_match BOOLEAN DEFAULT FALSE, UNIQUE(user_id, target_user_id) ); -- Matches table CREATE TABLE IF NOT EXISTS matches ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id_1 UUID REFERENCES users(id) ON DELETE CASCADE, user_id_2 UUID REFERENCES users(id) ON DELETE CASCADE, created_at TIMESTAMP DEFAULT NOW(), last_message_at TIMESTAMP, is_active BOOLEAN DEFAULT TRUE, is_super_match BOOLEAN DEFAULT FALSE, unread_count_1 INTEGER DEFAULT 0, unread_count_2 INTEGER DEFAULT 0, UNIQUE(user_id_1, user_id_2) ); -- Messages table CREATE TABLE IF NOT EXISTS messages ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), match_id UUID REFERENCES matches(id) ON DELETE CASCADE, sender_id UUID REFERENCES users(id) ON DELETE CASCADE, receiver_id UUID REFERENCES users(id) ON DELETE CASCADE, content TEXT NOT NULL, message_type VARCHAR(20) DEFAULT 'text' CHECK (message_type IN ('text', 'photo', 'gif', 'sticker')), created_at TIMESTAMP DEFAULT NOW(), is_read BOOLEAN DEFAULT FALSE ); ---------------------------------------------- -- Profile Views Table ---------------------------------------------- -- Table for tracking profile views CREATE TABLE IF NOT EXISTS profile_views ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), viewer_id UUID REFERENCES users(id) ON DELETE CASCADE, viewed_id UUID REFERENCES users(id) ON DELETE CASCADE, view_type VARCHAR(20) DEFAULT 'browse' CHECK (view_type IN ('browse', 'search', 'recommended')), viewed_at TIMESTAMP DEFAULT NOW(), CONSTRAINT unique_profile_view UNIQUE (viewer_id, viewed_id, view_type) ); -- Index for profile views CREATE INDEX IF NOT EXISTS idx_profile_views_viewer ON profile_views(viewer_id); CREATE INDEX IF NOT EXISTS idx_profile_views_viewed ON profile_views(viewed_id); ---------------------------------------------- -- Notification Tables ---------------------------------------------- -- Notifications table CREATE TABLE IF NOT EXISTS notifications ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, type VARCHAR(50) NOT NULL, content JSONB NOT NULL DEFAULT '{}', is_read BOOLEAN DEFAULT FALSE, processed BOOLEAN DEFAULT FALSE, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Notification settings table CREATE TABLE IF NOT EXISTS notification_settings ( user_id UUID PRIMARY KEY REFERENCES users(id) ON DELETE CASCADE, new_matches BOOLEAN DEFAULT TRUE, new_messages BOOLEAN DEFAULT TRUE, new_likes BOOLEAN DEFAULT TRUE, reminders BOOLEAN DEFAULT TRUE, daily_summary BOOLEAN DEFAULT FALSE, time_preference VARCHAR(20) DEFAULT 'evening', do_not_disturb BOOLEAN DEFAULT FALSE, do_not_disturb_start TIME, do_not_disturb_end TIME, updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Scheduled notifications table CREATE TABLE IF NOT EXISTS scheduled_notifications ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, type VARCHAR(50) NOT NULL, content JSONB NOT NULL DEFAULT '{}', scheduled_at TIMESTAMP WITH TIME ZONE NOT NULL, processed BOOLEAN DEFAULT FALSE, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); ---------------------------------------------- -- Indexes for better performance ---------------------------------------------- -- User Indexes CREATE INDEX IF NOT EXISTS idx_users_telegram_id ON users(telegram_id); -- Profile Indexes CREATE INDEX IF NOT EXISTS idx_profiles_user_id ON profiles(user_id); CREATE INDEX IF NOT EXISTS idx_profiles_location ON profiles(location_lat, location_lon) WHERE location_lat IS NOT NULL AND location_lon IS NOT NULL; CREATE INDEX IF NOT EXISTS idx_profiles_age_gender ON profiles(age, gender, interested_in); -- Swipe Indexes CREATE INDEX IF NOT EXISTS idx_swipes_user ON swipes(user_id, target_user_id); -- Match Indexes CREATE INDEX IF NOT EXISTS idx_matches_users ON matches(user_id_1, user_id_2); -- Message Indexes CREATE INDEX IF NOT EXISTS idx_messages_match ON messages(match_id, created_at); -- Notification Indexes CREATE INDEX IF NOT EXISTS idx_notifications_user_id ON notifications(user_id); CREATE INDEX IF NOT EXISTS idx_notifications_type ON notifications(type); CREATE INDEX IF NOT EXISTS idx_notifications_created_at ON notifications(created_at); CREATE INDEX IF NOT EXISTS idx_scheduled_notifications_user_id ON scheduled_notifications(user_id); CREATE INDEX IF NOT EXISTS idx_scheduled_notifications_scheduled_at ON scheduled_notifications(scheduled_at); CREATE INDEX IF NOT EXISTS idx_scheduled_notifications_processed ON scheduled_notifications(processed);