import {getClient} from "../utils/database.js"; import jwt from 'jsonwebtoken'; export async function getRecommendations(req, res) { const token = req.headers.authorization?.split(' ')[1]; if (!req.headers.authorization || !token) { // GET MOST USED TAGS let client = await getClient(); let queryMostUsedTags = `SELECT id, name FROM tags ORDER BY usage_count DESC LIMIT 3;`; let result = await client.query(queryMostUsedTags); // GET 10 VIDEOS WITH THE TAGS let tagIds = result.rows.map(tag => tag.id); let queryVideosWithTags = ` SELECT v.id, v.title, v.thumbnail, v.description AS video_description, v.channel, v.visibility, v.file, v.slug, v.release_date, v.channel AS channel_id, c.owner, COUNT(h.id) AS views, json_build_object( 'name', c.name, 'profilePicture', u.picture, 'description', c.description ) AS creator, 'video' AS type FROM public.videos v INNER JOIN public.video_tags vt ON v.id = vt.video INNER JOIN public.tags t ON vt.tag = t.id INNER JOIN public.channels c ON v.channel = c.id INNER JOIN public.users u ON c.owner = u.id LEFT JOIN public.history h ON h.video = v.id WHERE t.id = ANY($1::int[]) AND v.visibility = 'public' GROUP BY v.id, v.title, v.thumbnail, v.description, v.channel, v.visibility, v.file, v.slug, v.release_date, c.owner, c.name, u.picture, c.description ORDER BY views DESC, v.release_date DESC LIMIT 10; `; let videoResult = await client.query(queryVideosWithTags, [tagIds]); const recommendations = videoResult.rows; res.status(200).json(recommendations); } else { let client = await getClient(); const claims = jwt.decode(token) const query = ` -- Recommandation de contenu similaire non vu basée sur les interactions utilisateur -- Paramètre: $1 = user_id WITH user_interactions AS ( -- Récupérer tous les contenus avec lesquels l'utilisateur a interagi SELECT DISTINCT v.id as video_id, v.channel, t.id as tag_id, t.name as tag_name FROM videos v JOIN video_tags vt ON v.id = vt.video JOIN tags t ON vt.tag = t.id WHERE v.id IN ( -- Vidéos likées par l'utilisateur SELECT DISTINCT l.video FROM likes l WHERE l.owner = $1 UNION -- Vidéos commentées par l'utilisateur SELECT DISTINCT c.video FROM comments c WHERE c.author = $1 UNION -- Vidéos ajoutées aux playlists de l'utilisateur SELECT DISTINCT pe.video FROM playlist_elements pe JOIN playlists p ON pe.playlist = p.id WHERE p.owner = $1 ) ), user_preferred_tags AS ( -- Tags préférés basés sur les interactions SELECT tag_id, tag_name, COUNT(*) as interaction_count FROM user_interactions GROUP BY tag_id, tag_name ), user_preferred_channels AS ( -- Chaînes préférées basées sur les interactions SELECT channel, COUNT(*) as interaction_count FROM user_interactions GROUP BY channel ), unseen_videos AS ( -- Vidéos que l'utilisateur n'a jamais vues SELECT v.id, v.title, v.thumbnail, v.description, v.channel, v.visibility, v.file, v.slug, v.format, v.release_date, ch.owner FROM videos v JOIN channels ch ON v.channel = ch.id WHERE v.visibility = 'public' AND v.id NOT IN ( -- Exclure les vidéos déjà vues SELECT DISTINCT h.video FROM history h WHERE h.user_id = $1 UNION -- Exclure les vidéos déjà likées SELECT DISTINCT l.video FROM likes l WHERE l.owner = $1 UNION -- Exclure les vidéos déjà commentées SELECT DISTINCT c.video FROM comments c WHERE c.author = $1 UNION -- Exclure les vidéos déjà ajoutées aux playlists SELECT DISTINCT pe.video FROM playlist_elements pe JOIN playlists p ON pe.playlist = p.id WHERE p.owner = $1 ) ) -- Requête principale : recommander du contenu similaire SELECT uv.id, uv.title, uv.thumbnail, uv.description as video_description, uv.channel, uv.visibility, uv.file, uv.slug, uv.format, uv.release_date, uv.channel as channel_id, uv.owner, COALESCE(view_counts.views::text, '0') as views, json_build_object( 'name', u.username, 'profilePicture', u.picture, 'description', ch.description ) as creator, 'video' as type FROM unseen_videos uv JOIN channels ch ON uv.channel = ch.id JOIN users u ON ch.owner = u.id -- Compter les vues LEFT JOIN ( SELECT video, COUNT(*) as views FROM history GROUP BY video ) view_counts ON uv.id = view_counts.video -- Score basé sur les tags similaires LEFT JOIN ( SELECT vt.video, SUM(upt.interaction_count * 0.7) as score FROM video_tags vt JOIN user_preferred_tags upt ON vt.tag = upt.tag_id GROUP BY vt.video ) tag_score ON uv.id = tag_score.video -- Score basé sur les chaînes similaires LEFT JOIN ( SELECT uv2.channel, MAX(upc.interaction_count * 0.3) as score FROM unseen_videos uv2 JOIN user_preferred_channels upc ON uv2.channel = upc.channel GROUP BY uv2.channel ) channel_score ON uv.channel = channel_score.channel WHERE (tag_score.score > 0 OR channel_score.score > 0) -- Au moins une similarité GROUP BY uv.id, uv.title, uv.thumbnail, uv.description, uv.channel, uv.visibility, uv.file, uv.slug, uv.format, uv.release_date, uv.owner, u.username, u.picture, ch.description, view_counts.views, tag_score.score, channel_score.score ORDER BY (COALESCE(tag_score.score, 0) + COALESCE(channel_score.score, 0)) DESC, uv.release_date DESC LIMIT 20; `; let result = await client.query(query, [claims.id]); client.release() res.status(200).json(result.rows); } } export async function getTrendingVideos(req, res) { const client = await getClient(); try { // Optimized single query to get all trending video data let queryTrendingVideos = ` SELECT v.id, v.title, v.description, v.release_date, v.thumbnail, v.visibility, COUNT(DISTINCT l.id) AS like_count, COUNT(DISTINCT c.id) AS comment_count, COUNT(DISTINCT h.id) AS views, ch.id AS creator_id, ch.name AS creator_name, u.picture AS creator_profile_picture FROM videos v LEFT JOIN likes l ON v.id = l.video LEFT JOIN comments c ON v.id = c.video LEFT JOIN history h ON v.id = h.video LEFT JOIN channels ch ON v.channel = ch.id LEFT JOIN users u ON ch.owner = u.id WHERE v.visibility = 'public' GROUP BY v.id, ch.id, ch.name, u.picture ORDER BY like_count DESC, comment_count DESC, views DESC LIMIT 10 `; let result = await client.query(queryTrendingVideos); const trendingVideos = result.rows.map(video => ({ id: video.id, title: video.title, description: video.description, release_date: video.release_date, thumbnail: video.thumbnail, visibility: video.visibility, like_count: video.like_count, comment_count: video.comment_count, views: video.views, creator: { id: video.creator_id, name: video.creator_name, profilePicture: video.creator_profile_picture } })); res.status(200).json(trendingVideos); } catch (error) { console.error("Error fetching trending videos:", error); res.status(500).json({error: "Internal server error while fetching trending videos."}); } finally { client.release(); } } export async function getTopCreators(req, res) { const client = await getClient(); try { // GET TOP 5 CREATORS BASED ON NUMBER OF SUBSCRIBERS let queryTopCreators = ` SELECT c.id, c.name, c.description, u.picture AS profilePicture, COUNT(s.id) AS subscriber_count FROM channels c JOIN users u ON c.owner = u.id LEFT JOIN subscriptions s ON c.id = s.channel GROUP BY c.id, u.picture ORDER BY subscriber_count DESC LIMIT 10; `; let result = await client.query(queryTopCreators); const topCreators = result.rows; res.status(200).json(topCreators); } catch (error) { console.error("Error fetching top creators:", error); res.status(500).json({error: "Internal server error while fetching top creators."}); } finally { client.release(); } }