'use client'; import { useState } from 'react'; import { Button } from '@/components/ui/button'; import { Card, CardContent, CardHeader, CardTitle } from '@/components/ui/card'; import { Copy, Check } from 'lucide-react'; const SQL_SCHEMA = `-- Schéma simplifié et robuste pour l'application "Mes Budgets Participatifs" -- Architecture sans récursion RLS pour une installation simple et durable -- Supprimer les tables existantes dans l'ordre inverse des dépendances DROP TABLE IF EXISTS votes CASCADE; DROP TABLE IF EXISTS participants CASCADE; DROP TABLE IF EXISTS propositions CASCADE; DROP TABLE IF EXISTS campaigns CASCADE; DROP TABLE IF EXISTS settings CASCADE; DROP TABLE IF EXISTS admin_users CASCADE; DROP TABLE IF EXISTS user_permissions CASCADE; -- Supprimer les fonctions et triggers existants DROP FUNCTION IF EXISTS update_updated_at_column() CASCADE; DROP FUNCTION IF EXISTS generate_short_id() CASCADE; DROP FUNCTION IF EXISTS create_participant_with_short_id(UUID, TEXT, TEXT, TEXT) CASCADE; DROP FUNCTION IF EXISTS get_participant_total_votes(UUID) CASCADE; DROP FUNCTION IF EXISTS check_participant_budget(UUID, UUID) CASCADE; -- Table des permissions utilisateur (remplace admin_users) CREATE TABLE user_permissions ( user_id UUID PRIMARY KEY REFERENCES auth.users(id) ON DELETE CASCADE, is_admin BOOLEAN DEFAULT false, is_super_admin BOOLEAN DEFAULT false, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Table des campagnes CREATE TABLE campaigns ( id UUID DEFAULT gen_random_uuid() PRIMARY KEY, title TEXT NOT NULL, description TEXT NOT NULL, status TEXT NOT NULL CHECK (status IN ('deposit', 'voting', 'closed')) DEFAULT 'deposit', budget_per_user INTEGER NOT NULL CHECK (budget_per_user > 0), spending_tiers TEXT NOT NULL, -- Montants séparés par des virgules (ex: "10,25,50,100") slug TEXT UNIQUE, -- Slug unique pour les liens courts created_by UUID REFERENCES user_permissions(user_id), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Table des propositions CREATE TABLE propositions ( id UUID DEFAULT gen_random_uuid() PRIMARY KEY, campaign_id UUID NOT NULL REFERENCES campaigns(id) ON DELETE CASCADE, title TEXT NOT NULL, description TEXT NOT NULL, author_first_name TEXT NOT NULL, author_last_name TEXT NOT NULL, author_email TEXT NOT NULL, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Table des participants CREATE TABLE participants ( id UUID DEFAULT gen_random_uuid() PRIMARY KEY, campaign_id UUID NOT NULL REFERENCES campaigns(id) ON DELETE CASCADE, first_name TEXT NOT NULL, last_name TEXT NOT NULL, email TEXT NOT NULL, short_id TEXT UNIQUE, -- Identifiant court unique pour les liens de vote created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Table des votes CREATE TABLE votes ( id UUID DEFAULT gen_random_uuid() PRIMARY KEY, participant_id UUID NOT NULL REFERENCES participants(id) ON DELETE CASCADE, proposition_id UUID NOT NULL REFERENCES propositions(id) ON DELETE CASCADE, amount INTEGER NOT NULL CHECK (amount >= 0), created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), UNIQUE(participant_id, proposition_id) ); -- Table des paramètres CREATE TABLE settings ( key TEXT PRIMARY KEY, value TEXT NOT NULL, category TEXT DEFAULT 'general', description TEXT, created_at TIMESTAMP WITH TIME ZONE DEFAULT NOW(), updated_at TIMESTAMP WITH TIME ZONE DEFAULT NOW() ); -- Index pour améliorer les performances CREATE INDEX idx_campaigns_status ON campaigns(status); CREATE INDEX idx_campaigns_created_at ON campaigns(created_at); CREATE INDEX idx_propositions_campaign_id ON propositions(campaign_id); CREATE INDEX idx_participants_campaign_id ON participants(campaign_id); CREATE INDEX idx_participants_short_id ON participants(short_id); CREATE INDEX idx_votes_participant_id ON votes(participant_id); CREATE INDEX idx_votes_proposition_id ON votes(proposition_id); CREATE INDEX idx_settings_category ON settings(category); CREATE INDEX idx_user_permissions_admin ON user_permissions(is_admin); CREATE INDEX idx_user_permissions_super_admin ON user_permissions(is_super_admin); -- Politiques RLS simplifiées et non-récursives -- Activer RLS sur toutes les tables ALTER TABLE campaigns ENABLE ROW LEVEL SECURITY; ALTER TABLE propositions ENABLE ROW LEVEL SECURITY; ALTER TABLE participants ENABLE ROW LEVEL SECURITY; ALTER TABLE votes ENABLE ROW LEVEL SECURITY; ALTER TABLE settings ENABLE ROW LEVEL SECURITY; ALTER TABLE user_permissions ENABLE ROW LEVEL SECURITY; -- Politiques pour user_permissions (simples et non-récursives) CREATE POLICY "user_permissions_select" ON user_permissions FOR SELECT USING (auth.uid() IS NOT NULL); CREATE POLICY "user_permissions_manage_own" ON user_permissions FOR ALL USING (auth.uid() = user_id); -- Politiques pour les campagnes CREATE POLICY "Campagnes visibles par tous" ON campaigns FOR SELECT USING (true); CREATE POLICY "Seuls les admins peuvent créer/modifier les campagnes" ON campaigns FOR ALL USING ( EXISTS ( SELECT 1 FROM user_permissions WHERE user_permissions.user_id = auth.uid() AND user_permissions.is_admin = true ) ); -- Politiques pour les propositions CREATE POLICY "Propositions visibles par tous" ON propositions FOR SELECT USING (true); CREATE POLICY "Tout le monde peut créer des propositions" ON propositions FOR INSERT WITH CHECK (true); CREATE POLICY "Seuls les admins peuvent modifier/supprimer les propositions" ON propositions FOR UPDATE USING ( EXISTS ( SELECT 1 FROM user_permissions WHERE user_permissions.user_id = auth.uid() AND user_permissions.is_admin = true ) ); CREATE POLICY "Seuls les admins peuvent supprimer les propositions" ON propositions FOR DELETE USING ( EXISTS ( SELECT 1 FROM user_permissions WHERE user_permissions.user_id = auth.uid() AND user_permissions.is_admin = true ) ); -- Politiques pour les participants CREATE POLICY "Participants visibles par tous" ON participants FOR SELECT USING (true); CREATE POLICY "Seuls les admins peuvent gérer les participants" ON participants FOR ALL USING ( EXISTS ( SELECT 1 FROM user_permissions WHERE user_permissions.user_id = auth.uid() AND user_permissions.is_admin = true ) ); -- Politiques pour les votes CREATE POLICY "Votes visibles par tous" ON votes FOR SELECT USING (true); CREATE POLICY "Tout le monde peut créer/modifier ses votes" ON votes FOR ALL USING ( participant_id IN ( SELECT id FROM participants WHERE short_id = ( SELECT short_id FROM participants WHERE id = votes.participant_id ) ) ); -- Politiques pour les paramètres CREATE POLICY "Paramètres visibles par tous" ON settings FOR SELECT USING (true); CREATE POLICY "Seuls les admins peuvent gérer les paramètres" ON settings FOR ALL USING ( EXISTS ( SELECT 1 FROM user_permissions WHERE user_permissions.user_id = auth.uid() AND user_permissions.is_admin = true ) ); -- Fonctions utilitaires -- Fonction pour générer un short_id unique CREATE OR REPLACE FUNCTION generate_short_id() RETURNS TEXT AS $$ DECLARE chars TEXT := 'ABCDEFGHIJKLMNOPQRSTUVWXYZ0123456789'; result TEXT := ''; i INTEGER := 0; BEGIN FOR i IN 1..8 LOOP result := result || substr(chars, floor(random() * length(chars))::integer + 1, 1); END LOOP; RETURN result; END; $$ LANGUAGE plpgsql; -- Fonction pour générer un slug unique à partir d'un titre CREATE OR REPLACE FUNCTION generate_slug(title TEXT) RETURNS TEXT AS $$ DECLARE base_slug TEXT; final_slug TEXT; counter INTEGER := 0; max_attempts INTEGER := 10; BEGIN -- Convertir le titre en slug (minuscules, supprimer accents, remplacer espaces par tirets, supprimer caractères spéciaux) base_slug := lower(unaccent(title)); base_slug := regexp_replace(base_slug, '[^a-z0-9\s-]', '', 'g'); base_slug := regexp_replace(base_slug, '\s+', '-', 'g'); base_slug := regexp_replace(base_slug, '-+', '-', 'g'); base_slug := trim(both '-' from base_slug); -- Si le slug est vide, utiliser un slug par défaut IF base_slug = '' THEN base_slug := 'campagne'; END IF; -- Essayer de trouver un slug unique LOOP IF counter = 0 THEN final_slug := base_slug; ELSE final_slug := base_slug || '-' || counter; END IF; -- Vérifier si le slug existe déjà IF NOT EXISTS (SELECT 1 FROM campaigns WHERE campaigns.slug = final_slug) THEN RETURN final_slug; END IF; counter := counter + 1; -- Éviter les boucles infinies IF counter >= max_attempts THEN -- Utiliser un timestamp pour garantir l'unicité final_slug := base_slug || '-' || extract(epoch from now())::integer; RETURN final_slug; END IF; END LOOP; END; $$ LANGUAGE plpgsql; -- Fonction pour créer un participant avec short_id unique CREATE OR REPLACE FUNCTION create_participant_with_short_id( p_campaign_id UUID, p_first_name TEXT, p_last_name TEXT, p_email TEXT ) RETURNS UUID AS $$ DECLARE new_short_id TEXT; participant_id UUID; max_attempts INTEGER := 10; attempt INTEGER := 0; BEGIN LOOP new_short_id := generate_short_id(); attempt := attempt + 1; BEGIN INSERT INTO participants (campaign_id, first_name, last_name, email, short_id) VALUES (p_campaign_id, p_first_name, p_last_name, p_email, new_short_id) RETURNING id INTO participant_id; RETURN participant_id; EXCEPTION WHEN unique_violation THEN IF attempt >= max_attempts THEN RAISE EXCEPTION 'Impossible de générer un short_id unique après % tentatives', max_attempts; END IF; CONTINUE; END; END LOOP; END; $$ LANGUAGE plpgsql; -- Fonction pour calculer le total des votes d'un participant CREATE OR REPLACE FUNCTION get_participant_total_votes(p_participant_id UUID) RETURNS INTEGER AS $$ BEGIN RETURN COALESCE( (SELECT SUM(amount) FROM votes WHERE participant_id = p_participant_id), 0 ); END; $$ LANGUAGE plpgsql; -- Fonction pour vérifier si un participant a dépassé son budget CREATE OR REPLACE FUNCTION check_participant_budget( p_participant_id UUID, p_campaign_id UUID ) RETURNS BOOLEAN AS $$ DECLARE total_voted INTEGER; budget_limit INTEGER; BEGIN SELECT get_participant_total_votes(p_participant_id) INTO total_voted; SELECT budget_per_user FROM campaigns WHERE id = p_campaign_id INTO budget_limit; RETURN total_voted <= budget_limit; END; $$ LANGUAGE plpgsql; -- Triggers pour les timestamps automatiques CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = NOW(); RETURN NEW; END; $$ LANGUAGE plpgsql; CREATE TRIGGER update_campaigns_updated_at BEFORE UPDATE ON campaigns FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_votes_updated_at BEFORE UPDATE ON votes FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_settings_updated_at BEFORE UPDATE ON settings FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_user_permissions_updated_at BEFORE UPDATE ON user_permissions FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- Insérer les paramètres par défaut INSERT INTO settings (key, value, category, description) VALUES ('randomize_propositions', 'true', 'display', 'Afficher les propositions dans un ordre aléatoire'), ('propose_page_message', 'Partagez votre vision et proposez des projets qui feront la différence dans votre collectif. Votre voix compte pour façonner l''avenir de votre communauté.', 'display', 'Message affiché sur la page de dépôt de propositions'), ('footer_message', 'Développé avec ❤️ pour faciliter la démocratie participative - [Logiciel libre et open source](GITURL)', 'display', 'Message affiché en bas de page'), ('export_anonymization', 'full', 'export', 'Niveau d''anonymisation des exports') ON CONFLICT (key) DO NOTHING;`; export default function SqlSchemaDisplay() { const [copied, setCopied] = useState(false); const copyToClipboard = async () => { try { await navigator.clipboard.writeText(SQL_SCHEMA); setCopied(true); setTimeout(() => setCopied(false), 2000); } catch (err) { console.error('Erreur lors de la copie:', err); } }; return ( Script SQL à exécuter
{SQL_SCHEMA}
); }