improve security (change RLS, and allow table sensitive access only at server side, with supabase service key)
This commit is contained in:
247
database/supabase-schema.sql
Normal file
247
database/supabase-schema.sql
Normal file
@@ -0,0 +1,247 @@
|
||||
-- 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")
|
||||
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,
|
||||
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_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();
|
||||
|
||||
-- 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', 'false', '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;
|
||||
Reference in New Issue
Block a user