Files
peakskills/scripts/init.sql
Julien Froidefond 72b653de19 feat: refactor skills API and database schema
- Replaced file-based skill category loading with API calls in the GET and POST methods of the skills route.
- Added new `SkillsService` for handling skill category operations.
- Updated SQL initialization script to create `skill_categories`, `skills`, and `skill_links` tables with appropriate relationships.
- Enhanced `ApiClient` with methods for loading skill categories and creating new skills, improving API interaction.
- Introduced error handling for skill category creation and loading processes.
2025-08-21 09:55:35 +02:00

136 lines
4.7 KiB
PL/PgSQL

-- 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
CREATE TABLE users (
id SERIAL PRIMARY KEY,
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
);
-- User evaluations table
CREATE TABLE user_evaluations (
id SERIAL PRIMARY KEY,
user_id INTEGER REFERENCES users(id) ON DELETE CASCADE,
last_updated TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
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
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,
level skill_level_enum NOT NULL,
can_mentor BOOLEAN DEFAULT FALSE,
wants_to_learn BOOLEAN DEFAULT FALSE,
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
UNIQUE(category_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_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_skill_id ON skill_evaluations(skill_id);
-- 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();