Files
MOHPortalTest-AllAgents-All…/qwen/go/init.sql

161 lines
7.0 KiB
PL/PgSQL

-- Create the database schema for MerchantsOfHope.org recruiting platform
-- This includes multi-tenant architecture, user management, job positions, applications, etc.
-- Create extension for UUID generation if not exists
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
-- Tenants table - for multi-tenant architecture
CREATE TABLE tenants (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
name VARCHAR(255) NOT NULL,
slug VARCHAR(255) UNIQUE NOT NULL,
description TEXT,
logo_url VARCHAR(500),
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
is_active BOOLEAN DEFAULT TRUE
);
-- Users table
CREATE TABLE users (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
tenant_id UUID REFERENCES tenants(id) ON DELETE CASCADE,
email VARCHAR(255) UNIQUE NOT NULL,
username VARCHAR(255) UNIQUE,
first_name VARCHAR(100),
last_name VARCHAR(100),
phone VARCHAR(20),
role VARCHAR(50) DEFAULT 'job_seeker', -- job_seeker, job_provider, admin
password_hash VARCHAR(255), -- For local auth (not OIDC)
is_active BOOLEAN DEFAULT TRUE,
email_verified BOOLEAN DEFAULT FALSE,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
last_login TIMESTAMP WITH TIME ZONE,
CONSTRAINT valid_role CHECK (role IN ('job_seeker', 'job_provider', 'admin'))
);
-- OIDC identities table for external authentication
CREATE TABLE oidc_identities (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
user_id UUID REFERENCES users(id) ON DELETE CASCADE,
provider_name VARCHAR(100) NOT NULL,
provider_subject VARCHAR(255) NOT NULL,
provider_data JSONB, -- Store provider-specific user data
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
UNIQUE(user_id, provider_name),
UNIQUE(provider_name, provider_subject)
);
-- Social media identities table
CREATE TABLE social_identities (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
user_id UUID REFERENCES users(id) ON DELETE CASCADE,
provider_name VARCHAR(100) NOT NULL,
provider_user_id VARCHAR(255) NOT NULL,
access_token TEXT,
refresh_token TEXT,
expires_at TIMESTAMP WITH TIME ZONE,
profile_data JSONB, -- Store provider-specific profile data
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
UNIQUE(user_id, provider_name),
UNIQUE(provider_name, provider_user_id)
);
-- Job positions table
CREATE TABLE job_positions (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
tenant_id UUID REFERENCES tenants(id) ON DELETE CASCADE,
user_id UUID REFERENCES users(id) ON DELETE SET NULL, -- Creator of the position
title VARCHAR(255) NOT NULL,
description TEXT NOT NULL,
requirements TEXT,
location VARCHAR(255),
employment_type VARCHAR(50) DEFAULT 'full_time', -- full_time, part_time, contract, internship
salary_min DECIMAL(10,2),
salary_max DECIMAL(10,2),
experience_level VARCHAR(50) DEFAULT 'mid_level', -- entry_level, mid_level, senior_level, executive
posted_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
closed_at TIMESTAMP WITH TIME ZONE,
status VARCHAR(50) DEFAULT 'open', -- open, closed, filled
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
is_active BOOLEAN DEFAULT TRUE,
CONSTRAINT valid_employment_type CHECK (employment_type IN ('full_time', 'part_time', 'contract', 'internship')),
CONSTRAINT valid_experience_level CHECK (experience_level IN ('entry_level', 'mid_level', 'senior_level', 'executive')),
CONSTRAINT valid_status CHECK (status IN ('open', 'closed', 'filled'))
);
-- Resumes table
CREATE TABLE resumes (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
user_id UUID REFERENCES users(id) ON DELETE CASCADE,
title VARCHAR(255) NOT NULL,
file_path VARCHAR(500) NOT NULL, -- Path to stored resume file
file_type VARCHAR(100), -- MIME type
file_size INTEGER, -- Size in bytes
is_active BOOLEAN DEFAULT TRUE,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP
);
-- Applications table
CREATE TABLE applications (
id UUID PRIMARY KEY DEFAULT uuid_generate_v4(),
position_id UUID REFERENCES job_positions(id) ON DELETE CASCADE,
user_id UUID REFERENCES users(id) ON DELETE CASCADE,
resume_id UUID REFERENCES resumes(id) ON DELETE SET NULL,
cover_letter TEXT,
status VARCHAR(50) DEFAULT 'pending', -- pending, reviewed, accepted, rejected
applied_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
reviewed_at TIMESTAMP WITH TIME ZONE,
reviewer_user_id UUID REFERENCES users(id) ON DELETE SET NULL,
notes TEXT,
created_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP WITH TIME ZONE DEFAULT CURRENT_TIMESTAMP,
UNIQUE(position_id, user_id), -- Prevent duplicate applications
CONSTRAINT valid_status CHECK (status IN ('pending', 'reviewed', 'accepted', 'rejected'))
);
-- Indexes for better performance
CREATE INDEX idx_users_tenant_id ON users(tenant_id);
CREATE INDEX idx_users_email ON users(email);
CREATE INDEX idx_job_positions_tenant_id ON job_positions(tenant_id);
CREATE INDEX idx_job_positions_user_id ON job_positions(user_id);
CREATE INDEX idx_job_positions_status ON job_positions(status);
CREATE INDEX idx_applications_position_id ON applications(position_id);
CREATE INDEX idx_applications_user_id ON applications(user_id);
CREATE INDEX idx_applications_status ON applications(status);
CREATE INDEX idx_resumes_user_id ON resumes(user_id);
-- 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';
-- Triggers to automatically update the updated_at timestamp
CREATE TRIGGER update_tenants_updated_at BEFORE UPDATE ON tenants FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_job_positions_updated_at BEFORE UPDATE ON job_positions FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
CREATE TRIGGER update_resumes_updated_at BEFORE UPDATE ON resumes 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();
-- Insert default tenant for MerchantsOfHope
INSERT INTO tenants (name, slug, description)
VALUES ('MerchantsOfHope', 'merchants-of-hope', 'Default tenant for MerchantsOfHope.org platform');
-- Insert admin user for the default tenant
INSERT INTO users (tenant_id, email, username, first_name, last_name, role, is_active)
VALUES (
(SELECT id FROM tenants WHERE slug = 'merchants-of-hope'),
'admin@merchants-of-hope.org',
'admin',
'System',
'Administrator',
'admin',
true
);