-- Création des tables pour l'application "Mes Budgets Participatifs" -- 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_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); -- Index pour optimiser les requêtes CREATE INDEX idx_votes_campaign_participant ON votes(campaign_id, participant_id); CREATE INDEX idx_votes_proposition ON votes(proposition_id); -- 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(); -- Politique RLS (Row Level Security) - Activer pour 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; -- Politiques pour permettre l'accès public (à adapter selon vos besoins d'authentification) CREATE POLICY "Allow public read access to campaigns" ON campaigns FOR SELECT USING (true); CREATE POLICY "Allow public insert access to campaigns" ON campaigns FOR INSERT WITH CHECK (true); CREATE POLICY "Allow public update access to campaigns" ON campaigns FOR UPDATE USING (true); CREATE POLICY "Allow public delete access to campaigns" ON campaigns FOR DELETE USING (true); CREATE POLICY "Allow public read access to propositions" ON propositions FOR SELECT USING (true); CREATE POLICY "Allow public insert access to propositions" ON propositions FOR INSERT WITH CHECK (true); CREATE POLICY "Allow public delete access to propositions" ON propositions FOR DELETE USING (true); CREATE POLICY "Allow public read access to participants" ON participants FOR SELECT USING (true); CREATE POLICY "Allow public insert access to participants" ON participants FOR INSERT WITH CHECK (true); CREATE POLICY "Allow public delete access to participants" ON participants FOR DELETE USING (true); CREATE POLICY "Allow public read access to votes" ON votes FOR SELECT USING (true); CREATE POLICY "Allow public insert access to votes" ON votes FOR INSERT WITH CHECK (true); CREATE POLICY "Allow public update access to votes" ON votes FOR UPDATE USING (true); CREATE POLICY "Allow public delete access to votes" ON votes FOR DELETE USING (true); CREATE POLICY "Allow public read access to settings" ON settings FOR SELECT USING (true); CREATE POLICY "Allow public insert access to settings" ON settings FOR INSERT WITH CHECK (true); CREATE POLICY "Allow public update access to settings" ON settings FOR UPDATE USING (true); CREATE POLICY "Allow public delete access to settings" ON settings FOR DELETE USING (true); -- Données d'exemple (optionnel) INSERT INTO campaigns (title, description, status, budget_per_user, spending_tiers) VALUES ('Amélioration du quartier', 'Propositions pour améliorer notre quartier avec un budget participatif', 'deposit', 100, '10,25,50,100'), ('Équipements sportifs', 'Sélection d équipements sportifs pour la commune', 'voting', 50, '5,10,25,50'), ('Culture et loisirs', 'Projets culturels et de loisirs pour tous', 'closed', 75, '15,30,45,75'); -- 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');