20251017092737_da643bd1-b32d-454a-96c2-6062554cfaa7.sql 3.0 KB

1234567891011121314151617181920212223242526272829303132333435363738394041424344454647484950515253545556575859606162636465666768697071727374757677787980818283848586878889909192939495
  1. -- Étape 1: Ajouter la colonne read_count à la table user_articles
  2. ALTER TABLE public.user_articles
  3. ADD COLUMN IF NOT EXISTS read_count INTEGER NOT NULL DEFAULT 0;
  4. -- Étape 2: Créer la fonction trigger pour incrémenter read_count
  5. CREATE OR REPLACE FUNCTION public.increment_read_count()
  6. RETURNS TRIGGER
  7. LANGUAGE plpgsql
  8. SET search_path = public
  9. AS $$
  10. BEGIN
  11. -- Incrémenter uniquement si is_read passe de false à true
  12. IF NEW.is_read = true AND OLD.is_read = false THEN
  13. NEW.read_count = OLD.read_count + 1;
  14. END IF;
  15. RETURN NEW;
  16. END;
  17. $$;
  18. -- Étape 3: Créer le trigger sur user_articles
  19. DROP TRIGGER IF EXISTS trigger_increment_read_count ON public.user_articles;
  20. CREATE TRIGGER trigger_increment_read_count
  21. BEFORE UPDATE ON public.user_articles
  22. FOR EACH ROW
  23. EXECUTE FUNCTION public.increment_read_count();
  24. -- Étape 4: Vérifier et mettre à jour la foreign key avec CASCADE
  25. ALTER TABLE public.user_articles
  26. DROP CONSTRAINT IF EXISTS user_articles_article_id_fkey;
  27. ALTER TABLE public.user_articles
  28. ADD CONSTRAINT user_articles_article_id_fkey
  29. FOREIGN KEY (article_id)
  30. REFERENCES public.articles(id)
  31. ON DELETE CASCADE;
  32. -- Étape 5: Créer la fonction de purge automatique
  33. CREATE OR REPLACE FUNCTION public.purge_old_articles()
  34. RETURNS TABLE(
  35. deleted_count INTEGER,
  36. admin_emails TEXT[]
  37. )
  38. LANGUAGE plpgsql
  39. SECURITY DEFINER
  40. SET search_path = public
  41. AS $$
  42. DECLARE
  43. v_deleted_count INTEGER;
  44. v_admin_emails TEXT[];
  45. BEGIN
  46. -- Récupérer les emails des super users
  47. SELECT ARRAY_AGG(email) INTO v_admin_emails
  48. FROM public.super_users;
  49. -- Supprimer les articles de plus de 48h qui ne sont ni épinglés ni très lus
  50. WITH deleted AS (
  51. DELETE FROM public.articles
  52. WHERE id IN (
  53. SELECT a.id
  54. FROM public.articles a
  55. WHERE a.published_at < NOW() - INTERVAL '48 hours'
  56. AND NOT EXISTS (
  57. SELECT 1
  58. FROM public.user_articles ua
  59. WHERE ua.article_id = a.id
  60. AND (ua.is_pinned = true OR ua.read_count > 20)
  61. )
  62. )
  63. RETURNING id
  64. )
  65. SELECT COUNT(*) INTO v_deleted_count FROM deleted;
  66. -- Log l'opération
  67. RAISE NOTICE 'Purge automatique: % articles supprimés', v_deleted_count;
  68. -- Retourner les résultats
  69. RETURN QUERY SELECT v_deleted_count, v_admin_emails;
  70. END;
  71. $$;
  72. -- Étape 6: Activer l'extension pg_cron si pas déjà activée
  73. CREATE EXTENSION IF NOT EXISTS pg_cron;
  74. -- Étape 7: Créer le cron job pour exécuter tous les jours à 3h du matin
  75. SELECT cron.schedule(
  76. 'purge-old-articles-daily',
  77. '0 3 * * *', -- Tous les jours à 3h00 du matin
  78. $$
  79. SELECT net.http_post(
  80. url := 'https://wftyukugedtojizgatwj.supabase.co/functions/v1/purge-articles',
  81. headers := '{"Content-Type": "application/json", "Authorization": "Bearer eyJhbGciOiJIUzI1NiIsInR5cCI6IkpXVCJ9.eyJpc3MiOiJzdXBhYmFzZSIsInJlZiI6IndmdHl1a3VnZWR0b2ppemdhdHdqIiwicm9sZSI6ImFub24iLCJpYXQiOjE3NDkzNjIxNTEsImV4cCI6MjA2NDkzODE1MX0.KflrS6WiGksws1nO8NDm5i_Dav4u2JDSuEYtEnmKCRE"}'::jsonb,
  82. body := '{"scheduled": true}'::jsonb
  83. ) as request_id;
  84. $$
  85. );