164 lines
5.7 KiB
PL/PgSQL
164 lines
5.7 KiB
PL/PgSQL
-- Enable UUID extension for secure user identification
|
|
CREATE EXTENSION IF NOT EXISTS "uuid-ossp";
|
|
|
|
-- Create enum for skill levels
|
|
CREATE TYPE skill_level_enum AS ENUM ('never', 'not-autonomous', 'autonomous', 'expert');
|
|
|
|
-- Teams table
|
|
CREATE TABLE teams (
|
|
id VARCHAR(50) PRIMARY KEY,
|
|
name VARCHAR(100) NOT NULL,
|
|
direction VARCHAR(100) NOT NULL,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Skill categories table
|
|
CREATE TABLE skill_categories (
|
|
id VARCHAR(50) PRIMARY KEY,
|
|
name VARCHAR(100) NOT NULL,
|
|
icon VARCHAR(100) NOT NULL,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Skills table
|
|
CREATE TABLE skills (
|
|
id VARCHAR(100) PRIMARY KEY,
|
|
name VARCHAR(200) NOT NULL,
|
|
description TEXT,
|
|
icon VARCHAR(100),
|
|
category_id VARCHAR(50) REFERENCES skill_categories(id),
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Skill links table
|
|
CREATE TABLE skill_links (
|
|
id SERIAL PRIMARY KEY,
|
|
skill_id VARCHAR(100) REFERENCES skills(id) ON DELETE CASCADE,
|
|
url TEXT NOT NULL,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP
|
|
);
|
|
|
|
-- Users table with UUID primary key for security
|
|
-- UUIDs prevent user enumeration attacks (vs sequential IDs 1,2,3...)
|
|
CREATE TABLE users (
|
|
id SERIAL, -- Legacy ID kept for backward compatibility during migration
|
|
uuid_id UUID DEFAULT uuid_generate_v4() NOT NULL,
|
|
first_name VARCHAR(100) NOT NULL,
|
|
last_name VARCHAR(100) NOT NULL,
|
|
team_id VARCHAR(50) REFERENCES teams(id),
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
PRIMARY KEY (uuid_id),
|
|
UNIQUE(first_name, last_name, team_id),
|
|
UNIQUE(uuid_id)
|
|
);
|
|
|
|
-- ========================================
|
|
-- SIMPLIFIED EVALUATION SCHEMA
|
|
-- ========================================
|
|
|
|
-- User evaluations - metadata about user's evaluation session
|
|
CREATE TABLE user_evaluations (
|
|
id SERIAL PRIMARY KEY,
|
|
user_id INTEGER, -- Legacy column kept for backward compatibility
|
|
user_uuid UUID REFERENCES users(uuid_id) ON DELETE CASCADE,
|
|
last_updated TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
UNIQUE(user_uuid)
|
|
);
|
|
|
|
-- Skill evaluations - direct relationship between user and skill
|
|
CREATE TABLE skill_evaluations (
|
|
id SERIAL PRIMARY KEY,
|
|
user_evaluation_id INTEGER REFERENCES user_evaluations(id) ON DELETE CASCADE,
|
|
skill_id VARCHAR(100) REFERENCES skills(id) ON DELETE CASCADE,
|
|
level skill_level_enum NOT NULL,
|
|
can_mentor BOOLEAN DEFAULT FALSE,
|
|
wants_to_learn BOOLEAN DEFAULT FALSE,
|
|
is_selected BOOLEAN DEFAULT TRUE, -- Replaces selected_skills table
|
|
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
|
UNIQUE(user_evaluation_id, skill_id)
|
|
);
|
|
|
|
-- Insert initial teams data
|
|
INSERT INTO teams (id, name, direction) VALUES
|
|
('frontend', 'Frontend', 'Engineering'),
|
|
('backend', 'Backend', 'Engineering'),
|
|
('devops', 'DevOps', 'Engineering'),
|
|
('mobile', 'Mobile', 'Engineering'),
|
|
('data', 'Data Science', 'Engineering'),
|
|
('product', 'Product', 'Product'),
|
|
('design', 'Design', 'Product'),
|
|
('marketing', 'Marketing', 'Business');
|
|
|
|
-- Indexes for performance
|
|
CREATE INDEX idx_teams_direction ON teams(direction);
|
|
CREATE INDEX idx_skills_category_id ON skills(category_id);
|
|
CREATE INDEX idx_skill_links_skill_id ON skill_links(skill_id);
|
|
CREATE INDEX idx_users_team_id ON users(team_id);
|
|
CREATE INDEX idx_users_unique_person ON users(first_name, last_name, team_id);
|
|
CREATE INDEX idx_users_uuid_id ON users(uuid_id); -- Index on UUID for performance
|
|
CREATE INDEX idx_user_evaluations_user_uuid ON user_evaluations(user_uuid);
|
|
CREATE INDEX idx_user_evaluations_user_id ON user_evaluations(user_id); -- Legacy index
|
|
CREATE INDEX idx_skill_evaluations_user_evaluation_id ON skill_evaluations(user_evaluation_id);
|
|
CREATE INDEX idx_skill_evaluations_skill_id ON skill_evaluations(skill_id);
|
|
CREATE INDEX idx_skill_evaluations_is_selected ON skill_evaluations(is_selected);
|
|
|
|
-- Update trigger for users table
|
|
CREATE OR REPLACE FUNCTION update_updated_at_column()
|
|
RETURNS TRIGGER AS $$
|
|
BEGIN
|
|
NEW.updated_at = CURRENT_TIMESTAMP;
|
|
RETURN NEW;
|
|
END;
|
|
$$ language 'plpgsql';
|
|
|
|
CREATE TRIGGER update_teams_updated_at BEFORE UPDATE ON teams
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
CREATE TRIGGER update_skill_categories_updated_at BEFORE UPDATE ON skill_categories
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
CREATE TRIGGER update_skills_updated_at BEFORE UPDATE ON skills
|
|
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_skill_evaluations_updated_at BEFORE UPDATE ON skill_evaluations
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
-- Views for easy querying
|
|
CREATE VIEW user_skills_summary AS
|
|
SELECT
|
|
u.first_name,
|
|
u.last_name,
|
|
t.name as team_name,
|
|
t.direction,
|
|
sc.name as category_name,
|
|
s.name as skill_name,
|
|
se.level,
|
|
se.can_mentor,
|
|
se.wants_to_learn,
|
|
se.is_selected,
|
|
se.updated_at
|
|
FROM users u
|
|
JOIN teams t ON u.team_id = t.id
|
|
JOIN user_evaluations ue ON u.uuid_id = ue.user_uuid
|
|
JOIN skill_evaluations se ON ue.id = se.user_evaluation_id
|
|
JOIN skills s ON se.skill_id = s.id
|
|
JOIN skill_categories sc ON s.category_id = sc.id;
|
|
|
|
CREATE VIEW category_skills_count AS
|
|
SELECT
|
|
sc.id as category_id,
|
|
sc.name as category_name,
|
|
COUNT(s.id) as total_skills
|
|
FROM skill_categories sc
|
|
LEFT JOIN skills s ON sc.id = s.category_id
|
|
GROUP BY sc.id, sc.name;
|