-- ============================================ -- SCHEMA SQL - THE TIP TOP DATABASE -- ============================================ -- Drop tables if they exist DROP TABLE IF EXISTS tickets CASCADE; DROP TABLE IF EXISTS prizes CASCADE; DROP TABLE IF EXISTS users CASCADE; DROP TABLE IF EXISTS game_settings CASCADE; -- Drop types if they exist DROP TYPE IF EXISTS user_role CASCADE; DROP TYPE IF EXISTS ticket_status CASCADE; DROP TYPE IF EXISTS prize_type CASCADE; -- ============================================ -- ENUMS -- ============================================ CREATE TYPE user_role AS ENUM ('CLIENT', 'EMPLOYEE', 'ADMIN'); CREATE TYPE ticket_status AS ENUM ('PENDING', 'CLAIMED', 'REJECTED'); CREATE TYPE prize_type AS ENUM ( 'INFUSEUR', 'THE_SIGNATURE', 'COFFRET_DECOUVERTE', 'COFFRET_PRESTIGE', 'THE_GRATUIT' ); -- ============================================ -- TABLE: users -- ============================================ CREATE TABLE users ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), email VARCHAR(255) UNIQUE NOT NULL, password VARCHAR(255) NOT NULL, first_name VARCHAR(100) NOT NULL, last_name VARCHAR(100) NOT NULL, phone VARCHAR(20), address TEXT, city VARCHAR(100), postal_code VARCHAR(10), role user_role DEFAULT 'CLIENT', is_active BOOLEAN DEFAULT TRUE, is_verified BOOLEAN DEFAULT FALSE, verification_token VARCHAR(255), reset_token VARCHAR(255), reset_token_expiry TIMESTAMP, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Index pour améliorer les performances CREATE INDEX idx_users_email ON users(email); CREATE INDEX idx_users_role ON users(role); CREATE INDEX idx_users_verification_token ON users(verification_token); CREATE INDEX idx_users_reset_token ON users(reset_token); -- ============================================ -- TABLE: prizes -- ============================================ CREATE TABLE prizes ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), type prize_type NOT NULL, name VARCHAR(255) NOT NULL, description TEXT, value DECIMAL(10, 2) NOT NULL, stock INTEGER DEFAULT 0, probability DECIMAL(5, 4) NOT NULL CHECK (probability >= 0 AND probability <= 1), is_active BOOLEAN DEFAULT TRUE, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Index pour améliorer les performances CREATE INDEX idx_prizes_type ON prizes(type); CREATE INDEX idx_prizes_is_active ON prizes(is_active); -- ============================================ -- TABLE: tickets -- ============================================ CREATE TABLE tickets ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), code VARCHAR(50) UNIQUE NOT NULL, user_id UUID REFERENCES users(id) ON DELETE CASCADE, -- NULL = ticket non joué prize_id UUID NOT NULL REFERENCES prizes(id) ON DELETE RESTRICT, status ticket_status, -- NULL = ticket non joué, PENDING/CLAIMED/REJECTED après jeu played_at TIMESTAMP, -- NULL = ticket non joué, TIMESTAMP = date de jeu claimed_at TIMESTAMP, validated_by UUID REFERENCES users(id) ON DELETE SET NULL, validated_at TIMESTAMP, rejection_reason TEXT, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- Index pour améliorer les performances CREATE INDEX idx_tickets_code ON tickets(code); CREATE INDEX idx_tickets_user_id ON tickets(user_id); CREATE INDEX idx_tickets_status ON tickets(status); CREATE INDEX idx_tickets_prize_id ON tickets(prize_id); CREATE INDEX idx_tickets_validated_by ON tickets(validated_by); -- ============================================ -- TABLE: game_settings -- ============================================ CREATE TABLE game_settings ( id UUID PRIMARY KEY DEFAULT gen_random_uuid(), start_date TIMESTAMP NOT NULL, end_date TIMESTAMP NOT NULL, is_active BOOLEAN DEFAULT TRUE, total_tickets INTEGER NOT NULL, tickets_generated INTEGER DEFAULT 0, created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP, updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ); -- ============================================ -- TRIGGERS -- ============================================ -- Trigger pour mettre à jour updated_at automatiquement CREATE OR REPLACE FUNCTION update_updated_at_column() RETURNS TRIGGER AS $$ BEGIN NEW.updated_at = CURRENT_TIMESTAMP; RETURN NEW; END; $$ language 'plpgsql'; CREATE TRIGGER update_users_updated_at BEFORE UPDATE ON users FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_prizes_updated_at BEFORE UPDATE ON prizes FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_tickets_updated_at BEFORE UPDATE ON tickets FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); CREATE TRIGGER update_game_settings_updated_at BEFORE UPDATE ON game_settings FOR EACH ROW EXECUTE FUNCTION update_updated_at_column(); -- ============================================ -- INITIAL DATA -- ============================================ -- Configuration du jeu-concours Thé Tip Top -- Période de participation : 1 décembre 2025 au 31 décembre 2025 (30 jours) -- Période de récupération des lots : jusqu'au 31 janvier 2026 (60 jours) -- Tirage au sort : 1 février 2026 INSERT INTO game_settings (start_date, end_date, is_active, total_tickets) VALUES ('2025-12-01 00:00:00', '2025-12-31 23:59:59', TRUE, 500000); -- Prix avec probabilités respectant la distribution demandée -- Total: 500,000 tickets -- 1. Infuseur à thé (60% = 300,000) INSERT INTO prizes (type, name, description, value, stock, probability, is_active) VALUES ( 'INFUSEUR', 'Infuseur à thé', 'Un infuseur à thé de qualité supérieure en inox', 39.00, 300000, 0.60, TRUE ); -- 2. Boîte de 100g signature (20% = 100,000) INSERT INTO prizes (type, name, description, value, stock, probability, is_active) VALUES ( 'THE_SIGNATURE', 'Thé Signature 100g', 'Boîte de thé signature 100g - Mélange exclusif Thé Tip Top', 49.00, 100000, 0.20, TRUE ); -- 3. Coffret découverte (10% = 50,000) INSERT INTO prizes (type, name, description, value, stock, probability, is_active) VALUES ( 'COFFRET_DECOUVERTE', 'Coffret Découverte', 'Coffret découverte avec assortiment de 5 thés (39€)', 39.00, 50000, 0.10, TRUE ); -- 4. Coffret prestige (6% = 30,000) INSERT INTO prizes (type, name, description, value, stock, probability, is_active) VALUES ( 'COFFRET_PRESTIGE', 'Coffret Prestige', 'Coffret prestige avec sélection premium de thés rares (69€)', 69.00, 30000, 0.06, TRUE ); -- 5. Thé gratuit (4% = 20,000) INSERT INTO prizes (type, name, description, value, stock, probability, is_active) VALUES ( 'THE_GRATUIT', 'Thé Infusion Gratuit', 'Un thé infusion de votre choix offert en magasin', 0.00, 20000, 0.04, TRUE ); -- ============================================ -- VIEWS UTILES -- ============================================ -- Vue pour les statistiques des prix CREATE OR REPLACE VIEW prize_statistics AS SELECT p.id, p.name, p.type, p.stock AS stock_initial, COUNT(t.id) AS tickets_used, (p.stock - COUNT(t.id)) AS stock_remaining, COUNT(CASE WHEN t.status = 'CLAIMED' THEN 1 END) AS prizes_claimed, COUNT(CASE WHEN t.status = 'PENDING' THEN 1 END) AS prizes_pending, COUNT(CASE WHEN t.status = 'REJECTED' THEN 1 END) AS prizes_rejected FROM prizes p LEFT JOIN tickets t ON p.id = t.prize_id GROUP BY p.id, p.name, p.type, p.stock; -- Vue pour les tickets en attente de validation CREATE OR REPLACE VIEW pending_tickets AS SELECT t.id, t.code, t.status, t.played_at, u.email AS user_email, u.first_name || ' ' || u.last_name AS user_name, u.phone AS user_phone, p.name AS prize_name, p.type AS prize_type, p.value AS prize_value FROM tickets t JOIN users u ON t.user_id = u.id JOIN prizes p ON t.prize_id = p.id WHERE t.status = 'PENDING' ORDER BY t.played_at ASC; -- ============================================ -- COMMENTAIRES -- ============================================ COMMENT ON TABLE users IS 'Table des utilisateurs (clients, employés, admins)'; COMMENT ON TABLE prizes IS 'Table des prix disponibles dans le jeu'; COMMENT ON TABLE tickets IS 'Table des tickets de jeu joués par les utilisateurs'; COMMENT ON TABLE game_settings IS 'Configuration générale du jeu-concours'; COMMENT ON COLUMN users.role IS 'Rôle: CLIENT, EMPLOYEE, ou ADMIN'; COMMENT ON COLUMN prizes.probability IS 'Probabilité de gagner ce prix (0.0 à 1.0)'; COMMENT ON COLUMN tickets.status IS 'Statut: PENDING (en attente), CLAIMED (réclamé), REJECTED (rejeté)';