354 lines
12 KiB
PL/PgSQL
354 lines
12 KiB
PL/PgSQL
-- Schéma sécurisé pour l'application "Mes Budgets Participatifs"
|
|
|
|
-- Table des utilisateurs administrateurs (extension de auth.users)
|
|
CREATE TABLE admin_users (
|
|
id UUID REFERENCES auth.users(id) ON DELETE CASCADE PRIMARY KEY,
|
|
email TEXT NOT NULL,
|
|
role TEXT NOT NULL DEFAULT 'admin' CHECK (role IN ('admin', 'super_admin')),
|
|
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 admin_users(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,
|
|
campaign_id UUID NOT NULL REFERENCES campaigns(id) ON DELETE CASCADE,
|
|
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) -- Un seul vote par participant par proposition
|
|
);
|
|
|
|
-- Table des paramètres de l'application
|
|
CREATE TABLE settings (
|
|
id UUID DEFAULT gen_random_uuid() PRIMARY KEY,
|
|
key TEXT NOT NULL UNIQUE,
|
|
value TEXT NOT NULL,
|
|
category TEXT NOT NULL,
|
|
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_propositions_campaign_id ON propositions(campaign_id);
|
|
CREATE INDEX idx_participants_campaign_id ON participants(campaign_id);
|
|
CREATE INDEX idx_campaigns_status ON campaigns(status);
|
|
CREATE INDEX idx_campaigns_created_at ON campaigns(created_at DESC);
|
|
CREATE INDEX idx_campaigns_slug ON campaigns(slug);
|
|
CREATE INDEX idx_participants_short_id ON participants(short_id);
|
|
CREATE INDEX idx_votes_campaign_participant ON votes(campaign_id, participant_id);
|
|
CREATE INDEX idx_votes_proposition ON votes(proposition_id);
|
|
CREATE INDEX idx_admin_users_email ON admin_users(email);
|
|
|
|
-- Trigger pour mettre à jour updated_at automatiquement
|
|
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_admin_users_updated_at BEFORE UPDATE ON admin_users
|
|
FOR EACH ROW EXECUTE FUNCTION update_updated_at_column();
|
|
|
|
-- Fonction pour générer un slug à partir d'un titre
|
|
CREATE OR REPLACE FUNCTION generate_slug(title TEXT)
|
|
RETURNS TEXT AS $$
|
|
DECLARE
|
|
slug TEXT;
|
|
counter INTEGER := 0;
|
|
base_slug TEXT;
|
|
BEGIN
|
|
-- Convertir en minuscules et remplacer les caractères spéciaux
|
|
base_slug := lower(regexp_replace(title, '[^a-zA-Z0-9\s]', '', 'g'));
|
|
base_slug := regexp_replace(base_slug, '\s+', '-', 'g');
|
|
base_slug := trim(both '-' from base_slug);
|
|
|
|
-- Si le slug est vide, utiliser 'campagne'
|
|
IF base_slug = '' THEN
|
|
base_slug := 'campagne';
|
|
END IF;
|
|
|
|
slug := base_slug;
|
|
|
|
-- Vérifier si le slug existe déjà et ajouter un numéro si nécessaire
|
|
WHILE EXISTS (SELECT 1 FROM campaigns WHERE campaigns.slug = slug) LOOP
|
|
counter := counter + 1;
|
|
slug := base_slug || '-' || counter;
|
|
END LOOP;
|
|
|
|
RETURN slug;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- 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;
|
|
short_id TEXT;
|
|
counter INTEGER := 0;
|
|
BEGIN
|
|
LOOP
|
|
-- Générer un identifiant de 6 caractères
|
|
result := '';
|
|
FOR i IN 1..6 LOOP
|
|
result := result || substr(chars, floor(random() * length(chars))::integer + 1, 1);
|
|
END LOOP;
|
|
|
|
short_id := result;
|
|
|
|
-- Vérifier si le short_id existe déjà
|
|
IF NOT EXISTS (SELECT 1 FROM participants WHERE participants.short_id = short_id) THEN
|
|
RETURN short_id;
|
|
END IF;
|
|
|
|
-- Éviter les boucles infinies
|
|
counter := counter + 1;
|
|
IF counter > 100 THEN
|
|
RAISE EXCEPTION 'Impossible de générer un short_id unique après 100 tentatives';
|
|
END IF;
|
|
END LOOP;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
-- Activer RLS sur toutes les tables
|
|
ALTER TABLE admin_users ENABLE ROW LEVEL SECURITY;
|
|
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;
|
|
|
|
-- ========================================
|
|
-- POLITIQUES RLS SÉCURISÉES
|
|
-- ========================================
|
|
|
|
-- Fonction helper pour vérifier si l'utilisateur est admin
|
|
CREATE OR REPLACE FUNCTION is_admin()
|
|
RETURNS BOOLEAN AS $$
|
|
BEGIN
|
|
RETURN EXISTS (
|
|
SELECT 1 FROM admin_users
|
|
WHERE id = auth.uid()
|
|
);
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
|
|
|
-- Fonction helper pour vérifier si l'utilisateur est super admin
|
|
CREATE OR REPLACE FUNCTION is_super_admin()
|
|
RETURNS BOOLEAN AS $$
|
|
BEGIN
|
|
RETURN EXISTS (
|
|
SELECT 1 FROM admin_users
|
|
WHERE id = auth.uid() AND role = 'super_admin'
|
|
);
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
|
|
|
-- ========================================
|
|
-- POLITIQUES POUR admin_users
|
|
-- ========================================
|
|
-- Seuls les admins peuvent voir la liste des autres admins
|
|
CREATE POLICY "Admins can view admin users" ON admin_users
|
|
FOR SELECT USING (is_admin());
|
|
|
|
-- Seuls les super admins peuvent gérer les autres admins
|
|
CREATE POLICY "Super admins can manage admin users" ON admin_users
|
|
FOR ALL USING (is_super_admin());
|
|
|
|
-- ========================================
|
|
-- POLITIQUES POUR campaigns
|
|
-- ========================================
|
|
-- Lecture publique des campagnes (pour les pages publiques)
|
|
CREATE POLICY "Public read access to campaigns" ON campaigns
|
|
FOR SELECT USING (true);
|
|
|
|
-- Seuls les admins peuvent créer/modifier/supprimer des campagnes
|
|
CREATE POLICY "Admins can manage campaigns" ON campaigns
|
|
FOR ALL USING (is_admin());
|
|
|
|
-- ========================================
|
|
-- POLITIQUES POUR propositions
|
|
-- ========================================
|
|
-- Lecture publique des propositions (pour les pages publiques)
|
|
CREATE POLICY "Public read access to propositions" ON propositions
|
|
FOR SELECT USING (true);
|
|
|
|
-- Insertion publique des propositions (pour le dépôt public)
|
|
CREATE POLICY "Public insert access to propositions" ON propositions
|
|
FOR INSERT WITH CHECK (true);
|
|
|
|
-- Seuls les admins peuvent modifier/supprimer des propositions
|
|
CREATE POLICY "Admins can update propositions" ON propositions
|
|
FOR UPDATE USING (is_admin());
|
|
|
|
CREATE POLICY "Admins can delete propositions" ON propositions
|
|
FOR DELETE USING (is_admin());
|
|
|
|
-- ========================================
|
|
-- POLITIQUES POUR participants
|
|
-- ========================================
|
|
-- Lecture publique des participants (pour les pages de vote)
|
|
CREATE POLICY "Public read access to participants" ON participants
|
|
FOR SELECT USING (true);
|
|
|
|
-- Seuls les admins peuvent créer/modifier/supprimer des participants
|
|
CREATE POLICY "Admins can manage participants" ON participants
|
|
FOR ALL USING (is_admin());
|
|
|
|
-- ========================================
|
|
-- POLITIQUES POUR votes
|
|
-- ========================================
|
|
-- Lecture publique des votes (pour les statistiques)
|
|
CREATE POLICY "Public read access to votes" ON votes
|
|
FOR SELECT USING (true);
|
|
|
|
-- Insertion publique des votes (pour le vote public)
|
|
CREATE POLICY "Public insert access to votes" ON votes
|
|
FOR INSERT WITH CHECK (true);
|
|
|
|
-- Mise à jour publique des votes (pour modifier les votes)
|
|
CREATE POLICY "Public update access to votes" ON votes
|
|
FOR UPDATE USING (true);
|
|
|
|
-- Seuls les admins peuvent supprimer des votes
|
|
CREATE POLICY "Admins can delete votes" ON votes
|
|
FOR DELETE USING (is_admin());
|
|
|
|
-- ========================================
|
|
-- POLITIQUES POUR settings
|
|
-- ========================================
|
|
-- Lecture publique des paramètres (pour les fonctionnalités publiques)
|
|
CREATE POLICY "Public read access to settings" ON settings
|
|
FOR SELECT USING (true);
|
|
|
|
-- Seuls les admins peuvent gérer les paramètres
|
|
CREATE POLICY "Admins can manage settings" ON settings
|
|
FOR ALL USING (is_admin());
|
|
|
|
-- ========================================
|
|
-- DONNÉES D'EXEMPLE
|
|
-- ========================================
|
|
|
|
-- 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 lors du vote');
|
|
|
|
-- ========================================
|
|
-- FONCTIONS UTILITAIRES
|
|
-- ========================================
|
|
|
|
|
|
|
|
-- Fonction pour obtenir les statistiques d'une campagne (publique)
|
|
CREATE OR REPLACE FUNCTION get_campaign_stats(campaign_uuid UUID)
|
|
RETURNS TABLE(
|
|
total_propositions BIGINT,
|
|
total_participants BIGINT,
|
|
total_votes BIGINT,
|
|
total_budget_voted BIGINT
|
|
) AS $$
|
|
BEGIN
|
|
RETURN QUERY
|
|
SELECT
|
|
(SELECT COUNT(*) FROM propositions WHERE campaign_id = campaign_uuid) as total_propositions,
|
|
(SELECT COUNT(*) FROM participants WHERE campaign_id = campaign_uuid) as total_participants,
|
|
(SELECT COUNT(*) FROM votes WHERE campaign_id = campaign_uuid) as total_votes,
|
|
(SELECT COALESCE(SUM(amount), 0) FROM votes WHERE campaign_id = campaign_uuid) as total_budget_voted;
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|
|
|
|
-- Fonction pour remplacer tous les votes d'un participant de manière atomique
|
|
CREATE OR REPLACE FUNCTION replace_participant_votes(
|
|
p_campaign_id UUID,
|
|
p_participant_id UUID,
|
|
p_votes JSONB
|
|
)
|
|
RETURNS VOID AS $$
|
|
DECLARE
|
|
vote_record RECORD;
|
|
BEGIN
|
|
-- Commencer une transaction
|
|
BEGIN
|
|
-- Supprimer tous les votes existants pour ce participant dans cette campagne
|
|
DELETE FROM votes
|
|
WHERE campaign_id = p_campaign_id
|
|
AND participant_id = p_participant_id;
|
|
|
|
-- Insérer les nouveaux votes
|
|
FOR vote_record IN
|
|
SELECT * FROM jsonb_array_elements(p_votes)
|
|
LOOP
|
|
INSERT INTO votes (campaign_id, participant_id, proposition_id, amount)
|
|
VALUES (
|
|
p_campaign_id,
|
|
p_participant_id,
|
|
(vote_record.value->>'proposition_id')::UUID,
|
|
(vote_record.value->>'amount')::INTEGER
|
|
);
|
|
END LOOP;
|
|
|
|
-- La transaction sera automatiquement commitée si tout va bien
|
|
EXCEPTION
|
|
WHEN OTHERS THEN
|
|
-- En cas d'erreur, la transaction sera automatiquement rollbackée
|
|
RAISE EXCEPTION 'Erreur lors du remplacement des votes: %', SQLERRM;
|
|
END;
|
|
END;
|
|
$$ LANGUAGE plpgsql SECURITY DEFINER;
|