feat: update evaluation schema and refactor skill evaluations
- Added unique constraint on users table for first_name, last_name, and team_id. - Removed category_evaluations and selected_skills tables, simplifying the schema. - Updated skill_evaluations to directly reference user_evaluations and include is_selected flag. - Refactored EvaluationService to handle skill evaluations directly, improving data integrity and performance. - Introduced new queries for loading skills and evaluations, enhancing data retrieval efficiency. - Added views for user skills summary and category skills count for easier querying.
This commit is contained in:
@@ -45,10 +45,15 @@ CREATE TABLE users (
|
||||
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
|
||||
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
UNIQUE(first_name, last_name, team_id)
|
||||
);
|
||||
|
||||
-- User evaluations table
|
||||
-- ========================================
|
||||
-- SIMPLIFIED EVALUATION SCHEMA
|
||||
-- ========================================
|
||||
|
||||
-- User evaluations - metadata about user's evaluation session
|
||||
CREATE TABLE user_evaluations (
|
||||
id SERIAL PRIMARY KEY,
|
||||
user_id INTEGER REFERENCES users(id) ON DELETE CASCADE,
|
||||
@@ -57,35 +62,18 @@ CREATE TABLE user_evaluations (
|
||||
UNIQUE(user_id)
|
||||
);
|
||||
|
||||
-- Category evaluations table
|
||||
CREATE TABLE category_evaluations (
|
||||
id SERIAL PRIMARY KEY,
|
||||
user_evaluation_id INTEGER REFERENCES user_evaluations(id) ON DELETE CASCADE,
|
||||
category VARCHAR(100) NOT NULL,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
UNIQUE(user_evaluation_id, category)
|
||||
);
|
||||
|
||||
-- Selected skills table (skills the user wants to evaluate)
|
||||
CREATE TABLE selected_skills (
|
||||
id SERIAL PRIMARY KEY,
|
||||
category_evaluation_id INTEGER REFERENCES category_evaluations(id) ON DELETE CASCADE,
|
||||
skill_id VARCHAR(100) NOT NULL,
|
||||
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
|
||||
UNIQUE(category_evaluation_id, skill_id)
|
||||
);
|
||||
|
||||
-- Skill evaluations table
|
||||
-- Skill evaluations - direct relationship between user and skill
|
||||
CREATE TABLE skill_evaluations (
|
||||
id SERIAL PRIMARY KEY,
|
||||
category_evaluation_id INTEGER REFERENCES category_evaluations(id) ON DELETE CASCADE,
|
||||
skill_id VARCHAR(100) NOT NULL,
|
||||
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(category_evaluation_id, skill_id)
|
||||
UNIQUE(user_evaluation_id, skill_id)
|
||||
);
|
||||
|
||||
-- Insert initial teams data
|
||||
@@ -104,11 +92,11 @@ 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_user_evaluations_user_id ON user_evaluations(user_id);
|
||||
CREATE INDEX idx_category_evaluations_user_evaluation_id ON category_evaluations(user_evaluation_id);
|
||||
CREATE INDEX idx_selected_skills_category_evaluation_id ON selected_skills(category_evaluation_id);
|
||||
CREATE INDEX idx_skill_evaluations_category_evaluation_id ON skill_evaluations(category_evaluation_id);
|
||||
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()
|
||||
@@ -133,3 +121,33 @@ CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users
|
||||
|
||||
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.id = ue.user_id
|
||||
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;
|
||||
|
||||
Reference in New Issue
Block a user