feat: add PostgreSQL support and enhance evaluation loading

- Added `pg` and `@types/pg` dependencies for PostgreSQL integration.
- Updated `useEvaluation` hook to load user evaluations from the API, improving data management.
- Refactored `saveUserEvaluation` and `loadUserEvaluation` functions to interact with the API instead of localStorage.
- Introduced error handling for profile loading and evaluation saving to enhance robustness.
- Added new methods for managing user profiles and evaluations, including `clearUserProfile` and `loadEvaluationForProfile`.
This commit is contained in:
Julien Froidefond
2025-08-21 08:46:52 +02:00
parent 488684fd9b
commit 4e82a6d860
14 changed files with 1467 additions and 125 deletions

View File

@@ -0,0 +1,527 @@
import { getPool } from "./database";
import {
UserEvaluation,
UserProfile,
CategoryEvaluation,
SkillEvaluation,
SkillLevel,
} from "../lib/types";
export class EvaluationService {
/**
* Crée ou met à jour un utilisateur
*/
async upsertUser(profile: UserProfile): Promise<number> {
const pool = getPool();
const client = await pool.connect();
try {
// Vérifier si l'utilisateur existe déjà (par firstName + lastName + teamId)
const existingUserQuery = `
SELECT id FROM users
WHERE first_name = $1 AND last_name = $2 AND team_id = $3
`;
const existingUser = await client.query(existingUserQuery, [
profile.firstName,
profile.lastName,
profile.teamId,
]);
if (existingUser.rows.length > 0) {
// Mettre à jour l'utilisateur existant
const updateQuery = `
UPDATE users
SET first_name = $1, last_name = $2, team_id = $3, updated_at = CURRENT_TIMESTAMP
WHERE id = $4
RETURNING id
`;
const result = await client.query(updateQuery, [
profile.firstName,
profile.lastName,
profile.teamId,
existingUser.rows[0].id,
]);
return result.rows[0].id;
} else {
// Créer un nouvel utilisateur
const insertQuery = `
INSERT INTO users (first_name, last_name, team_id)
VALUES ($1, $2, $3)
RETURNING id
`;
const result = await client.query(insertQuery, [
profile.firstName,
profile.lastName,
profile.teamId,
]);
return result.rows[0].id;
}
} finally {
client.release();
}
}
/**
* Sauvegarde une évaluation utilisateur complète
*/
async saveUserEvaluation(evaluation: UserEvaluation): Promise<void> {
const pool = getPool();
const client = await pool.connect();
try {
await client.query("BEGIN");
// 1. Upsert user
const userId = await this.upsertUser(evaluation.profile);
// 2. Upsert user_evaluation
const userEvalQuery = `
INSERT INTO user_evaluations (user_id, last_updated)
VALUES ($1, $2)
ON CONFLICT (user_id)
DO UPDATE SET last_updated = $2
RETURNING id
`;
const userEvalResult = await client.query(userEvalQuery, [
userId,
new Date(evaluation.lastUpdated),
]);
const userEvaluationId = userEvalResult.rows[0].id;
// 3. Supprimer les anciennes évaluations de catégories
await client.query(
"DELETE FROM category_evaluations WHERE user_evaluation_id = $1",
[userEvaluationId]
);
// 4. Sauvegarder les nouvelles évaluations
for (const catEval of evaluation.evaluations) {
await this.saveCategoryEvaluation(client, userEvaluationId, catEval);
}
await client.query("COMMIT");
} catch (error) {
await client.query("ROLLBACK");
throw error;
} finally {
client.release();
}
}
/**
* Sauvegarde une évaluation de catégorie
*/
private async saveCategoryEvaluation(
client: any,
userEvaluationId: number,
catEval: CategoryEvaluation
): Promise<void> {
// Insérer la catégorie d'évaluation
const catEvalQuery = `
INSERT INTO category_evaluations (user_evaluation_id, category)
VALUES ($1, $2)
RETURNING id
`;
const catEvalResult = await client.query(catEvalQuery, [
userEvaluationId,
catEval.category,
]);
const categoryEvaluationId = catEvalResult.rows[0].id;
// Insérer les skills sélectionnées
for (const skillId of catEval.selectedSkillIds) {
await client.query(
"INSERT INTO selected_skills (category_evaluation_id, skill_id) VALUES ($1, $2)",
[categoryEvaluationId, skillId]
);
}
// Insérer les évaluations de skills
for (const skillEval of catEval.skills) {
if (skillEval.level !== null) {
await client.query(
`
INSERT INTO skill_evaluations
(category_evaluation_id, skill_id, level, can_mentor, wants_to_learn)
VALUES ($1, $2, $3, $4, $5)
`,
[
categoryEvaluationId,
skillEval.skillId,
skillEval.level,
skillEval.canMentor || false,
skillEval.wantsToLearn || false,
]
);
}
}
}
/**
* Charge une évaluation utilisateur
*/
async loadUserEvaluation(
profile: UserProfile
): Promise<UserEvaluation | null> {
const pool = getPool();
const client = await pool.connect();
try {
// Trouver l'utilisateur
const userQuery = `
SELECT u.*, ue.id as user_evaluation_id, ue.last_updated
FROM users u
LEFT JOIN user_evaluations ue ON u.id = ue.user_id
WHERE u.first_name = $1 AND u.last_name = $2 AND u.team_id = $3
`;
const userResult = await client.query(userQuery, [
profile.firstName,
profile.lastName,
profile.teamId,
]);
if (
userResult.rows.length === 0 ||
!userResult.rows[0].user_evaluation_id
) {
return null;
}
const userData = userResult.rows[0];
const userEvaluationId = userData.user_evaluation_id;
// Charger les évaluations de catégories
const categoriesQuery = `
SELECT ce.*,
array_agg(DISTINCT ss.skill_id) FILTER (WHERE ss.skill_id IS NOT NULL) as selected_skill_ids,
array_agg(
json_build_object(
'skillId', se.skill_id,
'level', se.level,
'canMentor', se.can_mentor,
'wantsToLearn', se.wants_to_learn
)
) FILTER (WHERE se.skill_id IS NOT NULL) as skill_evaluations
FROM category_evaluations ce
LEFT JOIN selected_skills ss ON ce.id = ss.category_evaluation_id
LEFT JOIN skill_evaluations se ON ce.id = se.category_evaluation_id
WHERE ce.user_evaluation_id = $1
GROUP BY ce.id, ce.category
ORDER BY ce.category
`;
const categoriesResult = await client.query(categoriesQuery, [
userEvaluationId,
]);
const evaluations: CategoryEvaluation[] = categoriesResult.rows.map(
(row) => ({
category: row.category,
selectedSkillIds: row.selected_skill_ids || [],
skills: (row.skill_evaluations || []).filter(
(se: any) => se.skillId !== null
),
})
);
return {
profile,
evaluations,
lastUpdated: userData.last_updated.toISOString(),
};
} finally {
client.release();
}
}
/**
* Met à jour le niveau d'une skill
*/
async updateSkillLevel(
profile: UserProfile,
category: string,
skillId: string,
level: SkillLevel
): Promise<void> {
const pool = getPool();
const client = await pool.connect();
try {
await client.query("BEGIN");
const userId = await this.upsertUser(profile);
// Obtenir ou créer user_evaluation
const userEvalResult = await client.query(
`
INSERT INTO user_evaluations (user_id, last_updated)
VALUES ($1, CURRENT_TIMESTAMP)
ON CONFLICT (user_id)
DO UPDATE SET last_updated = CURRENT_TIMESTAMP
RETURNING id
`,
[userId]
);
const userEvaluationId = userEvalResult.rows[0].id;
// Obtenir ou créer category_evaluation
const catEvalResult = await client.query(
`
INSERT INTO category_evaluations (user_evaluation_id, category)
VALUES ($1, $2)
ON CONFLICT (user_evaluation_id, category)
DO UPDATE SET category = $2
RETURNING id
`,
[userEvaluationId, category]
);
const categoryEvaluationId = catEvalResult.rows[0].id;
// Upsert skill evaluation
await client.query(
`
INSERT INTO skill_evaluations (category_evaluation_id, skill_id, level)
VALUES ($1, $2, $3)
ON CONFLICT (category_evaluation_id, skill_id)
DO UPDATE SET level = $3, updated_at = CURRENT_TIMESTAMP
`,
[categoryEvaluationId, skillId, level]
);
await client.query("COMMIT");
} catch (error) {
await client.query("ROLLBACK");
throw error;
} finally {
client.release();
}
}
/**
* Met à jour le statut de mentorat d'une skill
*/
async updateSkillMentorStatus(
profile: UserProfile,
category: string,
skillId: string,
canMentor: boolean
): Promise<void> {
await this.updateSkillProperty(
profile,
category,
skillId,
"can_mentor",
canMentor
);
}
/**
* Met à jour le statut d'apprentissage d'une skill
*/
async updateSkillLearningStatus(
profile: UserProfile,
category: string,
skillId: string,
wantsToLearn: boolean
): Promise<void> {
await this.updateSkillProperty(
profile,
category,
skillId,
"wants_to_learn",
wantsToLearn
);
}
/**
* Méthode utilitaire pour mettre à jour une propriété de skill
*/
private async updateSkillProperty(
profile: UserProfile,
category: string,
skillId: string,
property: "can_mentor" | "wants_to_learn",
value: boolean
): Promise<void> {
const pool = getPool();
const client = await pool.connect();
try {
await client.query("BEGIN");
const userId = await this.upsertUser(profile);
const userEvalResult = await client.query(
`
INSERT INTO user_evaluations (user_id, last_updated)
VALUES ($1, CURRENT_TIMESTAMP)
ON CONFLICT (user_id)
DO UPDATE SET last_updated = CURRENT_TIMESTAMP
RETURNING id
`,
[userId]
);
const userEvaluationId = userEvalResult.rows[0].id;
const catEvalResult = await client.query(
`
INSERT INTO category_evaluations (user_evaluation_id, category)
VALUES ($1, $2)
ON CONFLICT (user_evaluation_id, category)
DO UPDATE SET category = $2
RETURNING id
`,
[userEvaluationId, category]
);
const categoryEvaluationId = catEvalResult.rows[0].id;
// Update the specific property
const updateQuery = `
UPDATE skill_evaluations
SET ${property} = $3, updated_at = CURRENT_TIMESTAMP
WHERE category_evaluation_id = $1 AND skill_id = $2
`;
await client.query(updateQuery, [categoryEvaluationId, skillId, value]);
await client.query("COMMIT");
} catch (error) {
await client.query("ROLLBACK");
throw error;
} finally {
client.release();
}
}
/**
* Ajoute une skill à l'évaluation
*/
async addSkillToEvaluation(
profile: UserProfile,
category: string,
skillId: string
): Promise<void> {
const pool = getPool();
const client = await pool.connect();
try {
await client.query("BEGIN");
const userId = await this.upsertUser(profile);
const userEvalResult = await client.query(
`
INSERT INTO user_evaluations (user_id, last_updated)
VALUES ($1, CURRENT_TIMESTAMP)
ON CONFLICT (user_id)
DO UPDATE SET last_updated = CURRENT_TIMESTAMP
RETURNING id
`,
[userId]
);
const userEvaluationId = userEvalResult.rows[0].id;
const catEvalResult = await client.query(
`
INSERT INTO category_evaluations (user_evaluation_id, category)
VALUES ($1, $2)
ON CONFLICT (user_evaluation_id, category)
DO UPDATE SET category = $2
RETURNING id
`,
[userEvaluationId, category]
);
const categoryEvaluationId = catEvalResult.rows[0].id;
// Ajouter à selected_skills
await client.query(
`
INSERT INTO selected_skills (category_evaluation_id, skill_id)
VALUES ($1, $2)
ON CONFLICT DO NOTHING
`,
[categoryEvaluationId, skillId]
);
await client.query("COMMIT");
} catch (error) {
await client.query("ROLLBACK");
throw error;
} finally {
client.release();
}
}
/**
* Supprime une skill de l'évaluation
*/
async removeSkillFromEvaluation(
profile: UserProfile,
category: string,
skillId: string
): Promise<void> {
const pool = getPool();
const client = await pool.connect();
try {
await client.query("BEGIN");
// Trouver les IDs nécessaires
const findQuery = `
SELECT ce.id as category_evaluation_id
FROM users u
JOIN user_evaluations ue ON u.id = ue.user_id
JOIN category_evaluations ce ON ue.id = ce.user_evaluation_id
WHERE u.first_name = $1 AND u.last_name = $2 AND u.team_id = $3 AND ce.category = $4
`;
const result = await client.query(findQuery, [
profile.firstName,
profile.lastName,
profile.teamId,
category,
]);
if (result.rows.length > 0) {
const categoryEvaluationId = result.rows[0].category_evaluation_id;
// Supprimer de selected_skills et skill_evaluations
await client.query(
"DELETE FROM selected_skills WHERE category_evaluation_id = $1 AND skill_id = $2",
[categoryEvaluationId, skillId]
);
await client.query(
"DELETE FROM skill_evaluations WHERE category_evaluation_id = $1 AND skill_id = $2",
[categoryEvaluationId, skillId]
);
}
await client.query("COMMIT");
} catch (error) {
await client.query("ROLLBACK");
throw error;
} finally {
client.release();
}
}
}
// Instance singleton
export const evaluationService = new EvaluationService();