- Add slug/short_id fields to database with auto-generation

- Create migration script for existing data
- Update admin interface to show only short URLs
- Implement redirect system to avoid code duplication
- Maintain backward compatibility with old URLs
This commit is contained in:
Yannick Le Duc
2025-08-26 22:28:11 +02:00
parent bd4f63b99c
commit caf0478e02
12 changed files with 1040 additions and 110 deletions

View File

@@ -17,6 +17,7 @@ CREATE TABLE campaigns (
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()
@@ -41,6 +42,7 @@ CREATE TABLE participants (
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()
);
@@ -72,6 +74,8 @@ 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);
@@ -99,6 +103,69 @@ CREATE TRIGGER update_settings_updated_at BEFORE UPDATE ON settings
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;