-- JobForge MVP Database Initialization -- This file sets up the database schema with Row Level Security -- Enable required extensions CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; CREATE EXTENSION IF NOT EXISTS vector; -- Create custom types CREATE TYPE priority_level_type AS ENUM ('low', 'medium', 'high'); CREATE TYPE application_status_type AS ENUM ( 'draft', 'research_complete', 'resume_ready', 'cover_letter_ready' ); CREATE TYPE document_type_enum AS ENUM ( 'research_report', 'optimized_resume', 'cover_letter' ); CREATE TYPE focus_area_type AS ENUM ( 'software_development', 'data_science', 'management', 'consulting', 'other' ); -- Users table CREATE TABLE users ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), email VARCHAR(255) UNIQUE NOT NULL, password_hash VARCHAR(255) NOT NULL, full_name VARCHAR(255) NOT NULL, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), -- Constraints CONSTRAINT email_format CHECK (email ~* '^[A-Za-z0-9._%+-]+@[A-Za-z0-9.-]+\.[A-Za-z]{2,}$'), CONSTRAINT name_not_empty CHECK (LENGTH(TRIM(full_name)) > 0) ); -- Applications table CREATE TABLE applications ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, name VARCHAR(255) NOT NULL, company_name VARCHAR(255) NOT NULL, role_title VARCHAR(255) NOT NULL, job_url TEXT, job_description TEXT NOT NULL, location VARCHAR(255), priority_level priority_level_type DEFAULT 'medium', status application_status_type DEFAULT 'draft', -- Phase tracking research_completed BOOLEAN DEFAULT FALSE, resume_optimized BOOLEAN DEFAULT FALSE, cover_letter_generated BOOLEAN DEFAULT FALSE, -- Timestamps created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), -- Constraints CONSTRAINT job_description_min_length CHECK (LENGTH(job_description) >= 50), CONSTRAINT company_name_not_empty CHECK (LENGTH(TRIM(company_name)) > 0), CONSTRAINT role_title_not_empty CHECK (LENGTH(TRIM(role_title)) > 0), CONSTRAINT valid_job_url CHECK ( job_url IS NULL OR job_url ~* '^https?://[^\s/$.?#].[^\s]*$' ) ); -- Documents table CREATE TABLE documents ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), application_id UUID NOT NULL REFERENCES applications(id) ON DELETE CASCADE, document_type document_type_enum NOT NULL, content TEXT NOT NULL, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), -- Constraints CONSTRAINT content_min_length CHECK (LENGTH(content) >= 10), CONSTRAINT unique_document_per_application UNIQUE (application_id, document_type) ); -- User resumes table CREATE TABLE user_resumes ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), user_id UUID NOT NULL REFERENCES users(id) ON DELETE CASCADE, name VARCHAR(255) NOT NULL, content TEXT NOT NULL, focus_area focus_area_type DEFAULT 'other', is_primary BOOLEAN DEFAULT FALSE, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), -- Constraints CONSTRAINT resume_name_not_empty CHECK (LENGTH(TRIM(name)) > 0), CONSTRAINT resume_content_min_length CHECK (LENGTH(content) >= 100) ); -- Document embeddings table (for AI features) CREATE TABLE document_embeddings ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), document_id UUID NOT NULL REFERENCES documents(id) ON DELETE CASCADE, embedding vector(1536), -- OpenAI text-embedding-3-large dimension created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), -- Constraints CONSTRAINT unique_embedding_per_document UNIQUE (document_id) ); -- Create indexes CREATE INDEX idx_users_email ON users(email); CREATE INDEX idx_applications_user_id ON applications(user_id); CREATE INDEX idx_applications_status ON applications(status); CREATE INDEX idx_applications_created_at ON applications(created_at); CREATE INDEX idx_documents_application_id ON documents(application_id); CREATE INDEX idx_documents_type ON documents(document_type); CREATE INDEX idx_user_resumes_user_id ON user_resumes(user_id); CREATE INDEX idx_document_embeddings_document_id ON document_embeddings(document_id); -- Vector similarity index CREATE INDEX idx_document_embeddings_vector ON document_embeddings USING ivfflat (embedding vector_cosine_ops) WITH (lists = 100); -- Row Level Security setup ALTER TABLE users ENABLE ROW LEVEL SECURITY; ALTER TABLE applications ENABLE ROW LEVEL SECURITY; ALTER TABLE documents ENABLE ROW LEVEL SECURITY; ALTER TABLE user_resumes ENABLE ROW LEVEL SECURITY; ALTER TABLE document_embeddings ENABLE ROW LEVEL SECURITY; -- Helper function to get current user ID CREATE OR REPLACE FUNCTION get_current_user_id() RETURNS UUID AS $$ BEGIN RETURN current_setting('app.current_user_id')::UUID; EXCEPTION WHEN others THEN RETURN NULL; END; $$ LANGUAGE plpgsql SECURITY DEFINER; -- RLS policies CREATE POLICY users_own_data ON users FOR ALL USING (id = get_current_user_id()); CREATE POLICY applications_user_access ON applications FOR ALL USING (user_id = get_current_user_id()); CREATE POLICY documents_user_access ON documents FOR ALL USING ( application_id IN ( SELECT id FROM applications WHERE user_id = get_current_user_id() ) ); CREATE POLICY user_resumes_access ON user_resumes FOR ALL USING (user_id = get_current_user_id()); CREATE POLICY document_embeddings_access ON document_embeddings FOR ALL USING ( document_id IN ( SELECT d.id FROM documents d JOIN applications a ON d.application_id = a.id WHERE a.user_id = get_current_user_id() ) ); -- Trigger function for updating timestamps CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ LANGUAGE plpgsql; -- Apply timestamp triggers CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_applications_updated_at BEFORE UPDATE ON applications FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_documents_updated_at BEFORE UPDATE ON documents FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_user_resumes_updated_at BEFORE UPDATE ON user_resumes FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- Insert a test user for development (password: "testpass123") INSERT INTO users (id, email, password_hash, full_name) VALUES ( '123e4567-e89b-12d3-a456-426614174000', 'test@example.com', '$2b$12$LQv3c1yqBWVHxkd0LHAkCOYz6TtxMQJqhN8/LewgdyN8yF5V4M2kq', 'Test User' ) ON CONFLICT (email) DO NOTHING;