Files
MOHPortal/backend/src/database/schema.sql
ReachableCEO a553b14017
All checks were successful
CI / Backend Tests (push) Successful in 31s
CI / Frontend Tests (push) Successful in 1m43s
CI / Build Docker Images (push) Successful in 4m45s
ci: stabilize pipeline
2025-10-16 21:00:39 -05:00

153 lines
6.2 KiB
PL/PgSQL

-- MerchantsOfHope-SupplyANdDemandPortal Database Schema
-- Users table (for authentication and user management)
CREATE TABLE IF NOT EXISTS users (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
email VARCHAR(255) UNIQUE NOT NULL,
password_hash VARCHAR(255) NOT NULL,
first_name VARCHAR(100) NOT NULL,
last_name VARCHAR(100) NOT NULL,
role VARCHAR(50) NOT NULL CHECK (role IN ('admin', 'recruiter', 'employer', 'candidate')),
is_active BOOLEAN DEFAULT true,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- Employers table
CREATE TABLE IF NOT EXISTS employers (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID REFERENCES users(id) ON DELETE CASCADE,
company_name VARCHAR(255) NOT NULL,
industry VARCHAR(100),
company_size VARCHAR(50),
website VARCHAR(255),
description TEXT,
address TEXT,
phone VARCHAR(20),
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- Candidates table
CREATE TABLE IF NOT EXISTS candidates (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
user_id UUID REFERENCES users(id) ON DELETE CASCADE,
phone VARCHAR(20),
location VARCHAR(255),
linkedin_url VARCHAR(255),
github_url VARCHAR(255),
portfolio_url VARCHAR(255),
bio TEXT,
skills TEXT[],
experience_level VARCHAR(50),
availability VARCHAR(50),
salary_expectation INTEGER,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- Job postings table
CREATE TABLE IF NOT EXISTS jobs (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
employer_id UUID REFERENCES employers(id) ON DELETE CASCADE,
title VARCHAR(255) NOT NULL,
description TEXT NOT NULL,
requirements TEXT[],
responsibilities TEXT[],
location VARCHAR(255),
employment_type VARCHAR(50) CHECK (employment_type IN ('full-time', 'part-time', 'contract', 'internship')),
salary_min INTEGER,
salary_max INTEGER,
currency VARCHAR(3) DEFAULT 'USD',
status VARCHAR(50) DEFAULT 'active' CHECK (status IN ('active', 'paused', 'closed', 'draft')),
remote_allowed BOOLEAN DEFAULT false,
experience_level VARCHAR(50),
skills_required TEXT[],
benefits TEXT[],
application_deadline DATE,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- Applications table
CREATE TABLE IF NOT EXISTS applications (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
job_id UUID REFERENCES jobs(id) ON DELETE CASCADE,
candidate_id UUID REFERENCES candidates(id) ON DELETE CASCADE,
status VARCHAR(50) DEFAULT 'applied' CHECK (status IN ('applied', 'reviewed', 'shortlisted', 'interviewed', 'offered', 'rejected', 'withdrawn')),
cover_letter TEXT,
notes TEXT,
applied_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
UNIQUE(job_id, candidate_id)
);
-- Resumes table
CREATE TABLE IF NOT EXISTS resumes (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
candidate_id UUID REFERENCES candidates(id) ON DELETE CASCADE,
filename VARCHAR(255) NOT NULL,
original_name VARCHAR(255) NOT NULL,
file_path VARCHAR(500) NOT NULL,
file_size INTEGER NOT NULL,
mime_type VARCHAR(100) NOT NULL,
is_primary BOOLEAN DEFAULT false,
uploaded_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- Interviews table
CREATE TABLE IF NOT EXISTS interviews (
id UUID PRIMARY KEY DEFAULT gen_random_uuid(),
application_id UUID REFERENCES applications(id) ON DELETE CASCADE,
scheduled_at TIMESTAMP NOT NULL,
duration_minutes INTEGER DEFAULT 60,
interview_type VARCHAR(50) CHECK (interview_type IN ('phone', 'video', 'in-person', 'technical')),
location VARCHAR(255),
meeting_link VARCHAR(500),
notes TEXT,
status VARCHAR(50) DEFAULT 'scheduled' CHECK (status IN ('scheduled', 'completed', 'cancelled', 'rescheduled')),
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
);
-- Create indexes for better performance
CREATE INDEX IF NOT EXISTS idx_users_email ON users(email);
CREATE INDEX IF NOT EXISTS idx_users_role ON users(role);
CREATE INDEX IF NOT EXISTS idx_employers_user_id ON employers(user_id);
CREATE INDEX IF NOT EXISTS idx_candidates_user_id ON candidates(user_id);
CREATE INDEX IF NOT EXISTS idx_jobs_employer_id ON jobs(employer_id);
CREATE INDEX IF NOT EXISTS idx_jobs_status ON jobs(status);
CREATE INDEX IF NOT EXISTS idx_applications_job_id ON applications(job_id);
CREATE INDEX IF NOT EXISTS idx_applications_candidate_id ON applications(candidate_id);
CREATE INDEX IF NOT EXISTS idx_applications_status ON applications(status);
CREATE INDEX IF NOT EXISTS idx_resumes_candidate_id ON resumes(candidate_id);
CREATE INDEX IF NOT EXISTS idx_interviews_application_id ON interviews(application_id);
-- Create updated_at trigger function
CREATE OR REPLACE FUNCTION update_updated_at_column()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = CURRENT_TIMESTAMP;
RETURN NEW;
END;
$$ language 'plpgsql';
-- Apply updated_at triggers
DROP TRIGGER IF EXISTS update_users_updated_at ON users;
CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
DROP TRIGGER IF EXISTS update_employers_updated_at ON employers;
CREATE TRIGGER update_employers_updated_at BEFORE UPDATE ON employers FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
DROP TRIGGER IF EXISTS update_candidates_updated_at ON candidates;
CREATE TRIGGER update_candidates_updated_at BEFORE UPDATE ON candidates FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
DROP TRIGGER IF EXISTS update_jobs_updated_at ON jobs;
CREATE TRIGGER update_jobs_updated_at BEFORE UPDATE ON jobs FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
DROP TRIGGER IF EXISTS update_applications_updated_at ON applications;
CREATE TRIGGER update_applications_updated_at BEFORE UPDATE ON applications FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
DROP TRIGGER IF EXISTS update_interviews_updated_at ON interviews;
CREATE TRIGGER update_interviews_updated_at BEFORE UPDATE ON interviews FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();