Initial commit: AI Recruitment Site for Ryans Recruit Firm

- Complete PostgreSQL schema with migrations
- Node.js/Express backend with authentication
- Public website (home, about, services, jobs, apply, contact)
- Admin dashboard with applicant and job management
- CV upload and storage in PostgreSQL BYTEA
- Docker Compose setup for deployment
- Session-based authentication
- Responsive design with Ryan brand colors
This commit is contained in:
Mikael Westöö
2026-01-23 21:17:24 +01:00
commit 406d278a39
23 changed files with 3842 additions and 0 deletions

View File

@@ -0,0 +1,150 @@
-- AI Recruitment Site Database Schema
-- Using PostgreSQL with proper indexing and constraints
-- Admins table
CREATE TABLE IF NOT EXISTS admins (
id SERIAL PRIMARY KEY,
email VARCHAR(255) UNIQUE NOT NULL,
password_hash TEXT NOT NULL,
full_name VARCHAR(255) NOT NULL,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
last_login TIMESTAMP WITH TIME ZONE
);
-- Create index for faster email lookups
CREATE INDEX IF NOT EXISTS idx_admins_email ON admins(email);
-- Job postings table
CREATE TABLE IF NOT EXISTS job_postings (
id SERIAL PRIMARY KEY,
title VARCHAR(255) NOT NULL,
department VARCHAR(100),
location VARCHAR(255),
employment_type VARCHAR(50), -- Full-time, Part-time, Contract
salary_range VARCHAR(100),
description TEXT NOT NULL,
requirements TEXT,
benefits TEXT,
is_active BOOLEAN DEFAULT true,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
created_by INTEGER REFERENCES admins(id)
);
-- Create index for active jobs
CREATE INDEX IF NOT EXISTS idx_job_postings_active ON job_postings(is_active, created_at DESC);
-- Applicants table
CREATE TABLE IF NOT EXISTS applicants (
id SERIAL PRIMARY KEY,
full_name VARCHAR(255) NOT NULL,
email VARCHAR(255) NOT NULL,
phone VARCHAR(50),
linkedin_url VARCHAR(500),
portfolio_url VARCHAR(500),
years_of_experience INTEGER,
current_position VARCHAR(255),
current_company VARCHAR(255),
preferred_location VARCHAR(255),
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
-- Create index for applicant searches
CREATE INDEX IF NOT EXISTS idx_applicants_email ON applicants(email);
CREATE INDEX IF NOT EXISTS idx_applicants_name ON applicants(full_name);
CREATE INDEX IF NOT EXISTS idx_applicants_created_at ON applicants(created_at DESC);
-- Applications table (links applicants to jobs with CV)
CREATE TABLE IF NOT EXISTS applications (
id SERIAL PRIMARY KEY,
applicant_id INTEGER NOT NULL REFERENCES applicants(id) ON DELETE CASCADE,
job_id INTEGER REFERENCES job_postings(id) ON DELETE SET NULL,
cover_letter TEXT,
cv_filename VARCHAR(500),
cv_content_type VARCHAR(100),
cv_file BYTEA, -- Store CV as binary data
status VARCHAR(50) DEFAULT 'new', -- new, reviewing, interview, rejected, hired
notes TEXT,
applied_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
-- Create indexes for application queries
CREATE INDEX IF NOT EXISTS idx_applications_applicant ON applications(applicant_id);
CREATE INDEX IF NOT EXISTS idx_applications_job ON applications(job_id);
CREATE INDEX IF NOT EXISTS idx_applications_status ON applications(status);
CREATE INDEX IF NOT EXISTS idx_applications_date ON applications(applied_at DESC);
-- Add check constraint for application status
DO $$
BEGIN
IF NOT EXISTS (
SELECT 1 FROM pg_constraint
WHERE conname = 'applications_status_check'
) THEN
ALTER TABLE applications ADD CONSTRAINT applications_status_check
CHECK (status IN ('new', 'reviewing', 'interview', 'rejected', 'hired'));
END IF;
END $$;
-- Add check constraint for employment type
DO $$
BEGIN
IF NOT EXISTS (
SELECT 1 FROM pg_constraint
WHERE conname = 'job_postings_employment_type_check'
) THEN
ALTER TABLE job_postings ADD CONSTRAINT job_postings_employment_type_check
CHECK (employment_type IN ('Full-time', 'Part-time', 'Contract', 'Internship', 'Freelance'));
END IF;
END $$;
-- Contact submissions table
CREATE TABLE IF NOT EXISTS contact_submissions (
id SERIAL PRIMARY KEY,
name VARCHAR(255) NOT NULL,
email VARCHAR(255) NOT NULL,
subject VARCHAR(500),
message TEXT NOT NULL,
is_read BOOLEAN DEFAULT false,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
-- Create index for contact submissions
CREATE INDEX IF NOT EXISTS idx_contact_submissions_date ON contact_submissions(created_at DESC);
CREATE INDEX IF NOT EXISTS idx_contact_submissions_unread ON contact_submissions(is_read, created_at DESC);
-- Function to update the updated_at timestamp
CREATE OR REPLACE FUNCTION update_updated_at_column()
RETURNS TRIGGER AS $$
BEGIN
NEW.updated_at = CURRENT_TIMESTAMP;
RETURN NEW;
END;
$$ language 'plpgsql';
-- Trigger for job_postings
DO $$
BEGIN
IF NOT EXISTS (
SELECT 1 FROM pg_trigger WHERE tgname = 'update_job_postings_updated_at'
) THEN
CREATE TRIGGER update_job_postings_updated_at
BEFORE UPDATE ON job_postings
FOR EACH ROW
EXECUTE FUNCTION update_updated_at_column();
END IF;
END $$;
-- Trigger for applications
DO $$
BEGIN
IF NOT EXISTS (
SELECT 1 FROM pg_trigger WHERE tgname = 'update_applications_updated_at'
) THEN
CREATE TRIGGER update_applications_updated_at
BEFORE UPDATE ON applications
FOR EACH ROW
EXECUTE FUNCTION update_updated_at_column();
END IF;
END $$;