20251017093754_2858cb0a-5469-479b-9552-e53cfdd2dbb2.sql 2.8 KB

1234567891011121314151617181920212223242526272829303132333435363738394041424344454647484950515253545556575859606162636465666768697071727374757677787980818283848586878889909192939495969798
  1. -- Étape 1: Ajouter des index pour optimiser les requêtes de purge
  2. CREATE INDEX IF NOT EXISTS idx_articles_published_at ON public.articles(published_at);
  3. CREATE INDEX IF NOT EXISTS idx_user_articles_article_id_pinned ON public.user_articles(article_id, is_pinned);
  4. CREATE INDEX IF NOT EXISTS idx_user_articles_article_id_read_count ON public.user_articles(article_id, read_count);
  5. -- Étape 2: Optimiser la fonction de purge avec une approche plus rapide
  6. CREATE OR REPLACE FUNCTION public.purge_old_articles()
  7. RETURNS TABLE(
  8. deleted_count INTEGER,
  9. admin_emails TEXT[]
  10. )
  11. LANGUAGE plpgsql
  12. SECURITY DEFINER
  13. SET search_path = public
  14. AS $$
  15. DECLARE
  16. v_deleted_count INTEGER;
  17. v_admin_emails TEXT[];
  18. v_cutoff_date TIMESTAMP WITH TIME ZONE;
  19. BEGIN
  20. -- Calculer la date limite (48 heures)
  21. v_cutoff_date := NOW() - INTERVAL '48 hours';
  22. -- Récupérer les emails des super users
  23. SELECT ARRAY_AGG(email) INTO v_admin_emails
  24. FROM public.super_users;
  25. -- Supprimer les articles en une seule requête optimisée
  26. WITH articles_to_delete AS (
  27. SELECT a.id
  28. FROM public.articles a
  29. WHERE a.published_at < v_cutoff_date
  30. AND NOT EXISTS (
  31. SELECT 1
  32. FROM public.user_articles ua
  33. WHERE ua.article_id = a.id
  34. AND (ua.is_pinned = true OR ua.read_count > 20)
  35. )
  36. LIMIT 1000 -- Limiter pour éviter les timeouts
  37. ),
  38. deleted AS (
  39. DELETE FROM public.articles
  40. WHERE id IN (SELECT id FROM articles_to_delete)
  41. RETURNING id
  42. )
  43. SELECT COUNT(*)::INTEGER INTO v_deleted_count FROM deleted;
  44. -- Log l'opération
  45. RAISE NOTICE 'Purge automatique: % articles supprimés', v_deleted_count;
  46. -- Retourner les résultats
  47. RETURN QUERY SELECT v_deleted_count, v_admin_emails;
  48. END;
  49. $$;
  50. -- Étape 3: Créer une fonction de test pour la purge manuelle
  51. CREATE OR REPLACE FUNCTION public.test_purge_articles()
  52. RETURNS TABLE(
  53. articles_to_delete INTEGER,
  54. oldest_article_date TIMESTAMP WITH TIME ZONE,
  55. newest_article_date TIMESTAMP WITH TIME ZONE,
  56. sample_titles TEXT[]
  57. )
  58. LANGUAGE plpgsql
  59. SECURITY DEFINER
  60. SET search_path = public
  61. AS $$
  62. DECLARE
  63. v_cutoff_date TIMESTAMP WITH TIME ZONE;
  64. BEGIN
  65. v_cutoff_date := NOW() - INTERVAL '48 hours';
  66. RETURN QUERY
  67. WITH eligible_articles AS (
  68. SELECT a.id, a.published_at, a.title
  69. FROM public.articles a
  70. WHERE a.published_at < v_cutoff_date
  71. AND NOT EXISTS (
  72. SELECT 1
  73. FROM public.user_articles ua
  74. WHERE ua.article_id = a.id
  75. AND (ua.is_pinned = true OR ua.read_count > 20)
  76. )
  77. ),
  78. sample_articles AS (
  79. SELECT title
  80. FROM eligible_articles
  81. ORDER BY published_at DESC
  82. LIMIT 5
  83. )
  84. SELECT
  85. (SELECT COUNT(*)::INTEGER FROM eligible_articles),
  86. (SELECT MIN(published_at) FROM eligible_articles),
  87. (SELECT MAX(published_at) FROM eligible_articles),
  88. (SELECT ARRAY_AGG(title) FROM sample_articles)
  89. ;
  90. END;
  91. $$;