diff --git a/services/database.ts b/services/database.ts index 4d550a0..a14bd5b 100644 --- a/services/database.ts +++ b/services/database.ts @@ -7,6 +7,15 @@ const dbConfig = { database: process.env.DB_NAME || "peakskills", user: process.env.DB_USER || "peakskills_user", password: process.env.DB_PASSWORD || "peakskills_password", + // ✅ AJOUT : Configuration optimisée du pool + max: 20, // Connexions max + min: 2, // Connexions min + idleTimeoutMillis: 30000, // 30s + connectionTimeoutMillis: 2000, // 2s + acquireTimeoutMillis: 10000, // 10s + // Optimisations supplémentaires + allowExitOnIdle: true, + maxUses: 7500, // Recycler les connexions après 7500 utilisations }; // Pool de connexions global diff --git a/services/evaluation-service.ts b/services/evaluation-service.ts index 2475d63..131ec2a 100644 --- a/services/evaluation-service.ts +++ b/services/evaluation-service.ts @@ -207,43 +207,49 @@ export class EvaluationService { userEvaluationId: number, catEval: CategoryEvaluation ): Promise { - // Insérer les skills sélectionnées (sans évaluation) + // ✅ SOLUTION : BULK INSERT pour éviter les requêtes N+1 + const values = []; + const params = []; + let paramIndex = 1; + + // Préparer toutes les valeurs pour les skills sélectionnées for (const skillId of catEval.selectedSkillIds) { const isEvaluated = catEval.skills.some( (se) => se.skillId === skillId && se.level !== null ); if (!isEvaluated) { - // Skill sélectionnée mais pas encore évaluée - await client.query( - ` - INSERT INTO skill_evaluations - (user_evaluation_id, skill_id, level, is_selected, can_mentor, wants_to_learn) - VALUES ($1, $2, 'never'::skill_level_enum, true, false, false) - `, - [userEvaluationId, skillId] + values.push( + `($${paramIndex++}, $${paramIndex++}, 'never'::skill_level_enum, true, false, false)` + ); + params.push(userEvaluationId, skillId); + } + } + + // Préparer toutes les valeurs pour les évaluations de skills + for (const skillEval of catEval.skills) { + if (skillEval.level !== null) { + values.push( + `($${paramIndex++}, $${paramIndex++}, $${paramIndex++}, true, $${paramIndex++}, $${paramIndex++})` + ); + params.push( + userEvaluationId, + skillEval.skillId, + skillEval.level, + skillEval.canMentor || false, + skillEval.wantsToLearn || false ); } } - // Insérer les évaluations de skills - for (const skillEval of catEval.skills) { - if (skillEval.level !== null) { - await client.query( - ` - INSERT INTO skill_evaluations - (user_evaluation_id, skill_id, level, is_selected, can_mentor, wants_to_learn) - VALUES ($1, $2, $3, true, $4, $5) - `, - [ - userEvaluationId, - skillEval.skillId, - skillEval.level, - skillEval.canMentor || false, - skillEval.wantsToLearn || false, - ] - ); - } + // Exécuter le BULK INSERT si on a des valeurs + if (values.length > 0) { + const bulkQuery = ` + INSERT INTO skill_evaluations + (user_evaluation_id, skill_id, level, is_selected, can_mentor, wants_to_learn) + VALUES ${values.join(", ")} + `; + await client.query(bulkQuery, params); } } diff --git a/services/skills-service.ts b/services/skills-service.ts index a241d7f..9e9c3d5 100644 --- a/services/skills-service.ts +++ b/services/skills-service.ts @@ -7,60 +7,44 @@ export class SkillsService { */ 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, - s.id as skill_id, - s.name as skill_name, - s.description as skill_description, - s.icon as skill_icon, COALESCE( json_agg( - sl.url ORDER BY sl.id - ) FILTER (WHERE sl.url IS NOT NULL), + json_build_object( + 'id', s.id, + 'name', s.name, + 'description', s.description, + 'icon', s.icon, + '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 skill_links + ) as skills FROM skill_categories sc LEFT JOIN skills s ON sc.id = s.category_id - LEFT JOIN skill_links sl ON s.id = sl.skill_id - GROUP BY sc.id, sc.name, sc.icon, s.id, s.name, s.description, s.icon - ORDER BY sc.name, s.name + GROUP BY sc.id, sc.name, sc.icon + ORDER BY sc.name `; try { const result = await pool.query(query); - - // Group by category - const categoriesMap = new Map(); - - for (const row of result.rows) { - const categoryId = row.category_id; - - if (!categoriesMap.has(categoryId)) { - categoriesMap.set(categoryId, { - id: categoryId, - name: row.category_name, - category: row.category_name, - icon: row.category_icon, - skills: [], - }); - } - - if (row.skill_id) { - const category = categoriesMap.get(categoryId)!; - category.skills.push({ - id: row.skill_id, - name: row.skill_name, - description: row.skill_description, - icon: row.skill_icon, - links: row.skill_links, - }); - } - } - - return Array.from(categoriesMap.values()); + 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");