- Add database columns for last_employer_notification_at and last_employee_notification_at in cddu_contracts - Update all email sending endpoints to record timestamps (remind-employer, relance-salarie, docuseal-signature, signature-salarie) - Create smart reminder system with 24h cooldown to prevent spam - Add progress tracking modal with real-time status (pending/sending/success/error) - Display actual employer/employee email addresses in reminder modal - Show notification timestamps in contracts grid with color coding (green/orange/red based on contract start date) - Change employer email button URL from DocuSeal direct link to /signatures-electroniques - Create /api/staff/organizations/emails endpoint for bulk email fetching - Add retroactive migration script for historical email_logs data - Update Contract TypeScript type and API responses to include new fields
101 lines
3.8 KiB
SQL
101 lines
3.8 KiB
SQL
-- Migration pour rétroactivement associer les emails de signature aux contrats
|
|
-- À exécuter dans l'éditeur SQL de Supabase
|
|
|
|
-- Cette migration remplit le champ contract_id des emails de signature existants
|
|
-- en utilisant les données du template_data (contractReference, contract_number, etc.)
|
|
|
|
DO $$
|
|
DECLARE
|
|
updated_count INTEGER := 0;
|
|
email_record RECORD;
|
|
contract_reference TEXT;
|
|
found_contract_id UUID;
|
|
BEGIN
|
|
RAISE NOTICE 'Début de la migration des contract_id dans email_logs...';
|
|
|
|
-- Parcourir tous les emails de signature qui n'ont pas de contract_id
|
|
FOR email_record IN
|
|
SELECT id, template_data, subject
|
|
FROM email_logs
|
|
WHERE email_type IN ('signature-request-employer', 'signature-request-employee', 'signature-request-salarie')
|
|
AND contract_id IS NULL
|
|
AND template_data IS NOT NULL
|
|
LOOP
|
|
found_contract_id := NULL;
|
|
contract_reference := NULL;
|
|
|
|
-- Essayer d'extraire la référence du contrat depuis template_data
|
|
-- Les templates peuvent contenir contractReference, contract_number, ou reference
|
|
IF email_record.template_data ? 'contractReference' THEN
|
|
contract_reference := email_record.template_data->>'contractReference';
|
|
ELSIF email_record.template_data ? 'contract_number' THEN
|
|
contract_reference := email_record.template_data->>'contract_number';
|
|
ELSIF email_record.template_data ? 'reference' THEN
|
|
contract_reference := email_record.template_data->>'reference';
|
|
END IF;
|
|
|
|
-- Si on a trouvé une référence, chercher le contrat correspondant
|
|
IF contract_reference IS NOT NULL AND contract_reference != '' THEN
|
|
-- Chercher dans cddu_contracts par contract_number
|
|
SELECT id INTO found_contract_id
|
|
FROM cddu_contracts
|
|
WHERE contract_number = contract_reference
|
|
LIMIT 1;
|
|
|
|
-- Si pas trouvé, essayer avec la colonne reference (si elle existe)
|
|
IF found_contract_id IS NULL THEN
|
|
BEGIN
|
|
SELECT id INTO found_contract_id
|
|
FROM cddu_contracts
|
|
WHERE reference = contract_reference
|
|
LIMIT 1;
|
|
EXCEPTION
|
|
WHEN undefined_column THEN
|
|
-- La colonne reference n'existe pas, on ignore
|
|
NULL;
|
|
END;
|
|
END IF;
|
|
|
|
-- Mettre à jour l'email si on a trouvé un contrat
|
|
IF found_contract_id IS NOT NULL THEN
|
|
UPDATE email_logs
|
|
SET contract_id = found_contract_id
|
|
WHERE id = email_record.id;
|
|
|
|
updated_count := updated_count + 1;
|
|
|
|
IF updated_count % 100 = 0 THEN
|
|
RAISE NOTICE 'Progression: % emails mis à jour...', updated_count;
|
|
END IF;
|
|
END IF;
|
|
END IF;
|
|
END LOOP;
|
|
|
|
RAISE NOTICE 'Migration terminée: % emails mis à jour avec leur contract_id', updated_count;
|
|
|
|
-- Afficher quelques statistiques
|
|
RAISE NOTICE 'Statistiques après migration:';
|
|
RAISE NOTICE '- Emails de signature avec contract_id: %',
|
|
(SELECT COUNT(*) FROM email_logs
|
|
WHERE email_type IN ('signature-request-employer', 'signature-request-employee', 'signature-request-salarie')
|
|
AND contract_id IS NOT NULL);
|
|
RAISE NOTICE '- Emails de signature sans contract_id: %',
|
|
(SELECT COUNT(*) FROM email_logs
|
|
WHERE email_type IN ('signature-request-employer', 'signature-request-employee', 'signature-request-salarie')
|
|
AND contract_id IS NULL);
|
|
|
|
END $$;
|
|
|
|
-- Créer un index sur contract_id s'il n'existe pas déjà
|
|
CREATE INDEX IF NOT EXISTS idx_email_logs_contract_id ON email_logs(contract_id);
|
|
|
|
-- Afficher les résultats finaux
|
|
SELECT
|
|
email_type,
|
|
COUNT(*) as total,
|
|
COUNT(contract_id) as with_contract_id,
|
|
COUNT(*) - COUNT(contract_id) as without_contract_id
|
|
FROM email_logs
|
|
WHERE email_type IN ('signature-request-employer', 'signature-request-employee', 'signature-request-salarie')
|
|
GROUP BY email_type
|
|
ORDER BY email_type;
|