import { getPool } from "./database"; import { SkillCategory, Skill } from "@/lib/types"; export class SkillsService { /** * Get all skill categories with their skills */ static async getSkillCategories(): Promise { const pool = getPool(); // ✅ SOLUTION : Requête optimisée avec sous-requêtes const query = ` SELECT sc.id as category_id, sc.name as category_name, sc.icon as category_icon, COALESCE( json_agg( json_build_object( 'id', s.id, 'name', s.name, 'description', s.description, 'icon', s.icon, 'importance', s.importance, 'links', COALESCE( (SELECT json_agg(sl.url ORDER BY sl.id) FROM skill_links sl WHERE sl.skill_id = s.id), '[]'::json ) ) ORDER BY s.name ) FILTER (WHERE s.id IS NOT NULL), '[]'::json ) as skills FROM skill_categories sc LEFT JOIN skills s ON sc.id = s.category_id GROUP BY sc.id, sc.name, sc.icon ORDER BY sc.name `; try { const result = await pool.query(query); return result.rows.map((row) => ({ id: row.category_id, name: row.category_name, category: row.category_name, icon: row.category_icon, skills: row.skills, })); } catch (error) { console.error("Error fetching skill categories:", error); throw new Error("Failed to fetch skill categories"); } } /** * Get skills by category */ static async getSkillsByCategory(categoryId: string): Promise { const pool = getPool(); const query = ` SELECT s.id, s.name, s.description, s.icon, COALESCE( json_agg(sl.url ORDER BY sl.id) FILTER (WHERE sl.url IS NOT NULL), '[]'::json ) as links FROM skills s LEFT JOIN skill_links sl ON s.id = sl.skill_id WHERE s.category_id = $1 GROUP BY s.id, s.name, s.description, s.icon ORDER BY s.name `; try { const result = await pool.query(query, [categoryId]); return result.rows.map((row) => ({ id: row.id, name: row.name, description: row.description, icon: row.icon, links: row.links, })); } catch (error) { console.error("Error fetching skills by category:", error); throw new Error("Failed to fetch skills by category"); } } /** * Create a new skill category */ static async createSkillCategory(category: { id: string; name: string; icon: string; }): Promise { const pool = getPool(); const query = ` INSERT INTO skill_categories (id, name, icon) VALUES ($1, $2, $3) `; try { await pool.query(query, [category.id, category.name, category.icon]); } catch (error) { console.error("Error creating skill category:", error); throw new Error("Failed to create skill category"); } } /** * Create a new skill */ static async createSkill(skill: { id: string; name: string; description: string; icon?: string; categoryId: string; links: string[]; }): Promise { const pool = getPool(); const client = await pool.connect(); try { await client.query("BEGIN"); // Insert skill const skillQuery = ` INSERT INTO skills (id, name, description, icon, category_id) VALUES ($1, $2, $3, $4, $5) `; await client.query(skillQuery, [ skill.id, skill.name, skill.description, skill.icon, skill.categoryId, ]); // Insert links if (skill.links.length > 0) { const linkQuery = ` INSERT INTO skill_links (skill_id, url) VALUES ($1, $2) `; for (const link of skill.links) { await client.query(linkQuery, [skill.id, link]); } } await client.query("COMMIT"); } catch (error) { await client.query("ROLLBACK"); console.error("Error creating skill:", error); throw new Error("Failed to create skill"); } finally { client.release(); } } /** * Bulk insert skills from JSON data */ static async bulkInsertSkillsFromJSON( skillCategoriesData: SkillCategory[] ): Promise { const pool = getPool(); const client = await pool.connect(); try { await client.query("BEGIN"); for (const categoryData of skillCategoriesData) { const categoryId = categoryData.category.toLowerCase(); // Insert category const categoryQuery = ` INSERT INTO skill_categories (id, name, icon) VALUES ($1, $2, $3) ON CONFLICT (id) DO UPDATE SET name = EXCLUDED.name, icon = EXCLUDED.icon `; await client.query(categoryQuery, [ categoryId, categoryData.category, categoryData.icon, ]); // Insert skills for (const skill of categoryData.skills) { const skillQuery = ` INSERT INTO skills (id, name, description, icon, category_id) VALUES ($1, $2, $3, $4, $5) ON CONFLICT (id) DO UPDATE SET name = EXCLUDED.name, description = EXCLUDED.description, icon = EXCLUDED.icon, category_id = EXCLUDED.category_id `; await client.query(skillQuery, [ skill.id, skill.name, skill.description, skill.icon, categoryId, ]); // Delete existing links await client.query("DELETE FROM skill_links WHERE skill_id = $1", [ skill.id, ]); // Insert new links if (skill.links && skill.links.length > 0) { const linkQuery = ` INSERT INTO skill_links (skill_id, url) VALUES ($1, $2) `; for (const link of skill.links) { await client.query(linkQuery, [skill.id, link]); } } } } await client.query("COMMIT"); } catch (error) { await client.query("ROLLBACK"); console.error("Error bulk inserting skills:", error); throw new Error("Failed to bulk insert skills"); } finally { client.release(); } } /** * Get all skills with usage count for admin */ static async getAllSkillsWithUsage(): Promise< Array<{ id: string; name: string; description: string; icon: string; categoryId: string; category: string; usageCount: number; importance: string; }> > { const pool = getPool(); const query = ` SELECT s.id, s.name, s.description, s.icon, sc.id as category_id, sc.name as category_name, s.importance, COUNT(DISTINCT se.id) as usage_count FROM skills s LEFT JOIN skill_categories sc ON s.category_id = sc.id LEFT JOIN skill_evaluations se ON s.id = se.skill_id AND se.is_selected = true GROUP BY s.id, s.name, s.description, s.icon, sc.id, sc.name, s.importance ORDER BY s.name `; try { const result = await pool.query(query); return result.rows.map((row) => ({ id: row.id, name: row.name, description: row.description || "", icon: row.icon || "", categoryId: row.category_id, category: row.category_name, usageCount: parseInt(row.usage_count) || 0, importance: row.importance || "standard", })); } catch (error) { console.error("Error fetching skills with usage:", error); throw new Error("Failed to fetch skills with usage"); } } /** * Update skill importance */ static async updateSkillImportance( skillId: string, importance: "incontournable" | "majeure" | "standard" ): Promise { const pool = getPool(); const query = ` UPDATE skills SET importance = $1, updated_at = CURRENT_TIMESTAMP WHERE id = $2 `; try { const result = await pool.query(query, [importance, skillId]); if (result.rowCount === 0) { throw new Error("Skill not found"); } } catch (error) { console.error("Error updating skill importance:", error); throw new Error("Failed to update skill importance"); } } /** * Create a new skill for admin */ static async createSkillForAdmin(data: { name: string; categoryId: string; description?: string; icon?: string; }): Promise<{ id: string; name: string; description: string; icon: string; categoryId: string; category: string; usageCount: number; }> { const pool = getPool(); const client = await pool.connect(); try { await client.query("BEGIN"); // Vérifier si la skill existe déjà const existingSkill = await client.query( "SELECT id FROM skills WHERE LOWER(name) = LOWER($1)", [data.name] ); if (existingSkill.rows.length > 0) { throw new Error("Une skill avec ce nom existe déjà"); } // Créer la nouvelle skill const result = await client.query( `INSERT INTO skills (id, name, category_id, description, icon) VALUES (gen_random_uuid(), $1, $2, $3, $4) RETURNING id, name, description, icon, category_id`, [data.name, data.categoryId, data.description || "", data.icon || ""] ); const newSkill = result.rows[0]; // Récupérer le nom de la catégorie const categoryResult = await client.query( "SELECT name FROM skill_categories WHERE id = $1", [newSkill.category_id] ); await client.query("COMMIT"); return { id: newSkill.id, name: newSkill.name, description: newSkill.description, icon: newSkill.icon, categoryId: newSkill.category_id, category: categoryResult.rows[0]?.name || "Inconnue", usageCount: 0, }; } catch (error) { await client.query("ROLLBACK"); throw error; } finally { client.release(); } } /** * Update a skill for admin */ static async updateSkillForAdmin(data: { id: string; name: string; categoryId: string; description?: string; icon?: string; }): Promise<{ id: string; name: string; description: string; icon: string; categoryId: string; category: string; }> { const pool = getPool(); const client = await pool.connect(); try { await client.query("BEGIN"); // Vérifier si la skill existe const existingSkill = await client.query( "SELECT id FROM skills WHERE id = $1", [data.id] ); if (existingSkill.rows.length === 0) { throw new Error("Skill non trouvée"); } // Vérifier si le nom existe déjà (sauf pour cette skill) const duplicateName = await client.query( "SELECT id FROM skills WHERE LOWER(name) = LOWER($1) AND id != $2", [data.name, data.id] ); if (duplicateName.rows.length > 0) { throw new Error("Une skill avec ce nom existe déjà"); } // Mettre à jour la skill await client.query( `UPDATE skills SET name = $1, category_id = $2, description = $3, icon = $4 WHERE id = $5`, [ data.name, data.categoryId, data.description || "", data.icon || "", data.id, ] ); // Récupérer la skill mise à jour const result = await client.query( `SELECT s.id, s.name, s.description, s.icon, s.category_id, sc.name as category_name FROM skills s LEFT JOIN skill_categories sc ON s.category_id = sc.id WHERE s.id = $1`, [data.id] ); await client.query("COMMIT"); const skill = result.rows[0]; return { id: skill.id, name: skill.name, description: skill.description, icon: skill.icon, categoryId: skill.category_id, category: skill.category_name, }; } catch (error) { await client.query("ROLLBACK"); throw error; } finally { client.release(); } } /** * Delete a skill for admin */ static async deleteSkillForAdmin(id: string): Promise { const pool = getPool(); const client = await pool.connect(); try { await client.query("BEGIN"); // Vérifier si la skill est utilisée const usageCheck = await client.query( `SELECT COUNT(*) as count FROM skill_evaluations se WHERE se.skill_id = $1 AND se.is_selected = true`, [id] ); const usageCount = parseInt(usageCheck.rows[0].count); if (usageCount > 0) { throw new Error("Impossible de supprimer une skill qui est utilisée"); } // Supprimer la skill await client.query("DELETE FROM skills WHERE id = $1", [id]); await client.query("COMMIT"); } catch (error) { await client.query("ROLLBACK"); throw error; } finally { client.release(); } } }