#!/usr/bin/env php sourceDbName = $sourceDbName; $this->targetDbName = $targetDbName; $this->mode = $mode; $this->entityId = $entityId; $this->logFile = $logFile ?? '/var/back/migration_' . date('Ymd_His') . '.log'; $this->deleteBefore = $deleteBefore; $this->log("=== Migration depuis backup PM7 ==="); $this->log("Source: {$sourceDbName}"); $this->log("Cible: {$targetDbName}"); $this->log("Mode: {$mode}"); if ($entityId) { $this->log("Entité ID: {$entityId}"); } if ($deleteBefore) { $this->log("⚠️ Suppression des données existantes activée"); } } /** * Connexion aux bases de données */ public function connect() { try { // Connexion à la base source (backup restauré) - avec user ROOT pour accès multi-bases $dsn = sprintf('mysql:host=%s;port=%d;dbname=%s;charset=utf8mb4', self::DB_HOST, self::DB_PORT, $this->sourceDbName); $this->sourceDb = new PDO($dsn, self::DB_USER_ROOT, self::DB_PASS_ROOT, [ PDO::ATTR_ERRMODE => PDO::ERRMODE_EXCEPTION, PDO::ATTR_DEFAULT_FETCH_MODE => PDO::FETCH_ASSOC, PDO::ATTR_TIMEOUT => 600, PDO::MYSQL_ATTR_INIT_COMMAND => "SET NAMES utf8mb4" ]); $this->log("✓ Connexion à la base source: {$this->sourceDbName} sur " . self::DB_HOST); // Connexion à la base cible (pra_geo) - avec user dédié $dsn = sprintf('mysql:host=%s;port=%d;dbname=%s;charset=utf8mb4', self::DB_HOST, self::DB_PORT, $this->targetDbName); $this->targetDb = new PDO($dsn, self::DB_USER, self::DB_PASS, [ PDO::ATTR_ERRMODE => PDO::ERRMODE_EXCEPTION, PDO::ATTR_DEFAULT_FETCH_MODE => PDO::FETCH_ASSOC, PDO::ATTR_TIMEOUT => 600, PDO::MYSQL_ATTR_INIT_COMMAND => "SET NAMES utf8mb4" ]); $this->log("✓ Connexion à la base cible: {$this->targetDbName} sur " . self::DB_HOST); // Vérifier les versions MariaDB $sourceVersion = $this->sourceDb->query("SELECT VERSION()")->fetchColumn(); $targetVersion = $this->targetDb->query("SELECT VERSION()")->fetchColumn(); $this->log(" Source version: $sourceVersion"); $this->log(" Cible version: $targetVersion"); return true; } catch (PDOException $e) { $this->log("✗ Erreur de connexion: " . $e->getMessage(), 'ERROR'); return false; } } /** * Suppression des données d'une entité dans la TARGET * L'ordre de suppression respecte les contraintes FK (inverse de la migration) */ private function deleteEntityData($entityId) { try { $this->targetDb->beginTransaction(); // Ordre de suppression inverse pour respecter les FK $deletionOrder = [ 'medias', 'ope_pass_histo', 'ope_pass', 'ope_users_sectors', 'ope_users', 'sectors_adresses', 'ope_sectors', 'operations', 'users', // NE PAS supprimer entites car peut avoir d'autres données liées ]; foreach ($deletionOrder as $table) { $deleted = 0; switch ($table) { case 'users': $stmt = $this->targetDb->prepare("DELETE FROM $table WHERE fk_entite = ?"); $stmt->execute([$entityId]); $deleted = $stmt->rowCount(); break; case 'operations': $stmt = $this->targetDb->prepare("DELETE FROM $table WHERE fk_entite = ?"); $stmt->execute([$entityId]); $deleted = $stmt->rowCount(); break; case 'sectors_adresses': // Via ope_sectors -> operations $stmt = $this->targetDb->prepare(" DELETE sa FROM $table sa INNER JOIN ope_sectors s ON sa.fk_sector = s.id INNER JOIN operations o ON s.fk_operation = o.id WHERE o.fk_entite = ? "); $stmt->execute([$entityId]); $deleted = $stmt->rowCount(); break; case 'medias': // Medias peut avoir fk_entite OU fk_operation $stmt = $this->targetDb->prepare(" DELETE FROM $table WHERE fk_entite = ? OR fk_operation IN (SELECT id FROM operations WHERE fk_entite = ?) "); $stmt->execute([$entityId, $entityId]); $deleted = $stmt->rowCount(); break; case 'ope_pass_histo': // Via ope_pass -> operations $stmt = $this->targetDb->prepare(" DELETE h FROM $table h INNER JOIN ope_pass p ON h.fk_pass = p.id INNER JOIN operations o ON p.fk_operation = o.id WHERE o.fk_entite = ? "); $stmt->execute([$entityId]); $deleted = $stmt->rowCount(); break; default: // Tables avec fk_operation directe (ope_pass, ope_users, ope_users_sectors, ope_sectors) $stmt = $this->targetDb->prepare(" DELETE t FROM $table t INNER JOIN operations o ON t.fk_operation = o.id WHERE o.fk_entite = ? "); $stmt->execute([$entityId]); $deleted = $stmt->rowCount(); break; } if ($deleted > 0) { $this->log(" ✓ $table: $deleted ligne(s) supprimée(s)"); } } $this->targetDb->commit(); $this->log("✓ Suppression terminée\n"); } catch (PDOException $e) { if ($this->targetDb->inTransaction()) { $this->targetDb->rollBack(); } $this->log("✗ Erreur lors de la suppression: " . $e->getMessage(), 'ERROR'); throw $e; } } /** * Exécution de la migration */ public function migrate() { $startTime = microtime(true); $totalRecords = 0; $totalErrors = 0; try { if ($this->mode === 'global') { // Migration globale de toutes les amicales $this->log("\n=== Migration GLOBALE de toutes les amicales ===\n"); foreach ($this->migrationSteps as $step) { $this->log("--- Migration: $step ---"); $result = $this->migrateTable($step); $totalRecords += $result['success']; $totalErrors += $result['errors']; $this->log(" ✓ Réussis: {$result['success']}, Erreurs: {$result['errors']}"); } } elseif ($this->mode === 'entity' && $this->entityId) { // Migration d'une amicale spécifique $this->log("\n=== Migration de l'amicale ID: {$this->entityId} ===\n"); // Vérifier que l'entité existe dans la source $stmt = $this->sourceDb->prepare("SELECT rowid, libelle FROM users_entites WHERE rowid = ?"); $stmt->execute([$this->entityId]); $entity = $stmt->fetch(); if (!$entity) { $this->log("✗ Entité ID {$this->entityId} introuvable dans la source", 'ERROR'); return false; } $this->log("Entité trouvée: {$entity['libelle']}"); // Supprimer les données existantes si demandé if ($this->deleteBefore) { $this->log("\n⚠️ Suppression des données existantes de l'entité..."); $this->deleteEntityData($this->entityId); } // Migrer les données de l'entité $entityTables = ['entites', 'users', 'operations', 'ope_sectors', 'sectors_adresses', 'ope_users', 'ope_users_sectors', 'ope_pass', 'ope_pass_histo', 'medias']; // Compteurs pour le résumé $stats = ['entites' => 0, 'users' => 0, 'operations' => 0, 'ope_sectors' => 0, 'sectors_adresses' => 0, 'ope_users' => 0, 'ope_users_sectors' => 0, 'ope_pass' => 0, 'ope_pass_histo' => 0, 'medias' => 0]; foreach ($entityTables as $table) { $this->log("--- Migration: $table (entité {$this->entityId}) ---"); $result = $this->migrateTable($table, $this->entityId); $totalRecords += $result['success']; $totalErrors += $result['errors']; $stats[$table] = $result['success']; $this->log(" ✓ Réussis: {$result['success']}, Erreurs: {$result['errors']}"); } // Ligne spéciale pour parsing par le script bash // Note: sectorFromGPS sera défini dans la fonction migrateOpePass, donc on ne l'a pas ici $this->log("#STATS# OPE:{$stats['operations']} USER:{$stats['users']} SECTOR:{$stats['ope_sectors']} PASS:{$stats['ope_pass']} #END#"); } else { $this->log("✗ Mode invalide ou entity_id manquant", 'ERROR'); return false; } $duration = round(microtime(true) - $startTime, 2); $this->log("\n=== Migration terminée ==="); $this->log("Durée totale: {$duration}s"); $this->log("Total enregistrements migrés: $totalRecords"); $this->log("Total erreurs: $totalErrors"); return true; } catch (Exception $e) { $this->log("✗ Erreur critique: " . $e->getMessage(), 'ERROR'); return false; } } /** * Migration d'une table spécifique */ private function migrateTable($tableName, $entityId = null) { try { switch ($tableName) { // Tables de référence (x_*) case 'x_devises': case 'x_entites_types': case 'x_types_passages': case 'x_types_reglements': case 'x_users_roles': case 'x_users_titres': return $this->migrateReferenceTable($tableName, $entityId); // Tables géographiques (avec FK vers x_devises, x_regions, x_pays) case 'x_pays': case 'x_regions': case 'x_departements': case 'x_villes': return $this->migrateGeoTable($tableName, $entityId); // Tables principales case 'entites': return $this->migrateEntites($entityId); case 'users': return $this->migrateUsers($entityId); case 'operations': return $this->migrateOperations($entityId); case 'ope_sectors': return $this->migrateOpeSectors($entityId); case 'sectors_adresses': return $this->migrateSectorsAdresses($entityId); case 'ope_users': return $this->migrateOpeUsers($entityId); case 'ope_users_sectors': return $this->migrateOpeUsersSectors($entityId); case 'ope_pass': return $this->migrateOpePass($entityId); case 'ope_pass_histo': return $this->migrateOpePassHisto($entityId); case 'medias': return $this->migrateMedias($entityId); default: $this->log(" ⚠ Table non gérée: $tableName", 'WARNING'); return ['success' => 0, 'errors' => 0]; } } catch (Exception $e) { $this->log(" ✗ Erreur lors de la migration de $tableName: " . $e->getMessage(), 'ERROR'); return ['success' => 0, 'errors' => 1]; } } /** * Migration des tables de référence simples (sans FK) */ private function migrateReferenceTable($tableName, $entityId = null) { $success = 0; $errors = 0; try { // Récupérer toutes les données de la source $stmt = $this->sourceDb->query("SELECT * FROM $tableName"); $rows = $stmt->fetchAll(); if (empty($rows)) { $this->log(" → Aucune donnée à migrer pour $tableName"); return ['success' => 0, 'errors' => 0]; } // Préparer la requête d'insertion $columns = array_keys($rows[0]); $placeholders = array_map(fn($col) => ":$col", $columns); $sql = sprintf( "INSERT INTO %s (%s) VALUES (%s) ON DUPLICATE KEY UPDATE %s", $tableName, implode(', ', $columns), implode(', ', $placeholders), implode(', ', array_map(fn($col) => "$col = VALUES($col)", $columns)) ); $insertStmt = $this->targetDb->prepare($sql); // Insérer chaque ligne foreach ($rows as $row) { try { $insertStmt->execute($row); $success++; } catch (PDOException $e) { $this->log(" ✗ Erreur insertion $tableName: " . $e->getMessage(), 'ERROR'); $errors++; } } } catch (Exception $e) { $this->log(" ✗ Erreur migration $tableName: " . $e->getMessage(), 'ERROR'); $errors++; } return ['success' => $success, 'errors' => $errors]; } /** * Compte le nombre de lignes dans une table TARGET pour une entité donnée */ private function countTargetRows(string $tableName, $entityId = null): int { try { if ($entityId) { // Pour entites : juste l'ID if ($tableName === 'entites') { $sql = "SELECT COUNT(*) as count FROM $tableName WHERE id = :entity_id"; $stmt = $this->targetDb->prepare($sql); $stmt->execute(['entity_id' => $entityId]); } // Pour users : fk_entite else if ($tableName === 'users') { $sql = "SELECT COUNT(*) as count FROM $tableName WHERE fk_entite = :entity_id"; $stmt = $this->targetDb->prepare($sql); $stmt->execute(['entity_id' => $entityId]); } // Pour operations : fk_entite directe else if ($tableName === 'operations') { $sql = "SELECT COUNT(*) as count FROM $tableName WHERE fk_entite = :entity_id"; $stmt = $this->targetDb->prepare($sql); $stmt->execute(['entity_id' => $entityId]); } // Pour sectors_adresses : via ope_sectors else if ($tableName === 'sectors_adresses') { $sql = "SELECT COUNT(*) as count FROM $tableName sa INNER JOIN ope_sectors s ON sa.fk_sector = s.id INNER JOIN operations o ON s.fk_operation = o.id WHERE o.fk_entite = :entity_id"; $stmt = $this->targetDb->prepare($sql); $stmt->execute(['entity_id' => $entityId]); } // Pour ope_pass_histo : via ope_pass else if ($tableName === 'ope_pass_histo') { $sql = "SELECT COUNT(*) as count FROM $tableName h INNER JOIN ope_pass p ON h.fk_pass = p.id INNER JOIN operations o ON p.fk_operation = o.id WHERE o.fk_entite = :entity_id"; $stmt = $this->targetDb->prepare($sql); $stmt->execute(['entity_id' => $entityId]); } // Pour medias : peut avoir fk_entite OU fk_operation else if ($tableName === 'medias') { $sql = "SELECT COUNT(*) as count FROM $tableName WHERE fk_entite = :entity_id OR fk_operation IN (SELECT id FROM operations WHERE fk_entite = :entity_id2)"; $stmt = $this->targetDb->prepare($sql); $stmt->execute(['entity_id' => $entityId, 'entity_id2' => $entityId]); } // Pour les tables avec fk_operation directe else if (in_array($tableName, ['ope_sectors', 'ope_users', 'ope_users_sectors', 'ope_pass'])) { $sql = "SELECT COUNT(*) as count FROM $tableName t INNER JOIN operations o ON t.fk_operation = o.id WHERE o.fk_entite = :entity_id"; $stmt = $this->targetDb->prepare($sql); $stmt->execute(['entity_id' => $entityId]); } else { return 0; } } else { $sql = "SELECT COUNT(*) as count FROM $tableName"; $stmt = $this->targetDb->prepare($sql); $stmt->execute(); } $result = $stmt->fetch(PDO::FETCH_ASSOC); return (int)$result['count']; } catch (PDOException $e) { $this->log(" ⚠ Erreur comptage TARGET $tableName: " . $e->getMessage(), 'WARNING'); return 0; } } /** * Migration des tables géographiques (avec FK) */ private function migrateGeoTable($tableName, $entityId = null) { // Utiliser la même logique que les tables de référence // car elles respectent déjà l'ordre des FK return $this->migrateReferenceTable($tableName, $entityId); } /** * Migration de la table entites (avec chiffrement) */ private function migrateEntites($entityId = null) { $success = 0; $errors = 0; try { // Construire la requête de sélection // Mapping: users_entites (source) → entites (cible) $sql = "SELECT rowid, libelle, adresse1, adresse2, cp, ville, fk_region, fk_type, tel1, tel2, email, gps_lat, gps_lng, iban, bic, demo, chk_mdp_manuel, chk_copie_mail_recu, chk_accept_sms, date_modif, fk_user_modif, active FROM users_entites"; if ($entityId) { $sql .= " WHERE rowid = :entity_id"; } $stmt = $this->sourceDb->prepare($sql); if ($entityId) { $stmt->execute(['entity_id' => $entityId]); } else { $stmt->execute(); } $rows = $stmt->fetchAll(); $this->log(" → " . count($rows) . " entité(s) trouvée(s) dans SOURCE"); if (empty($rows)) { $this->log(" → Aucune entité à migrer"); return ['success' => 0, 'errors' => 0]; } // Préparer l'insertion $insertSql = "INSERT INTO entites ( id, encrypted_name, adresse1, adresse2, code_postal, ville, fk_region, fk_type, encrypted_phone, encrypted_mobile, encrypted_email, gps_lat, gps_lng, chk_stripe, encrypted_stripe_id, encrypted_iban, encrypted_bic, chk_demo, chk_mdp_manuel, chk_username_manuel, chk_user_delete_pass, chk_copie_mail_recu, chk_accept_sms, chk_lot_actif, created_at, fk_user_creat, updated_at, fk_user_modif, chk_active ) VALUES ( :id, :encrypted_name, :adresse1, :adresse2, :code_postal, :ville, :fk_region, :fk_type, :encrypted_phone, :encrypted_mobile, :encrypted_email, :gps_lat, :gps_lng, :chk_stripe, :encrypted_stripe_id, :encrypted_iban, :encrypted_bic, :chk_demo, :chk_mdp_manuel, :chk_username_manuel, :chk_user_delete_pass, :chk_copie_mail_recu, :chk_accept_sms, :chk_lot_actif, :created_at, :fk_user_creat, :updated_at, :fk_user_modif, :chk_active ) ON DUPLICATE KEY UPDATE encrypted_name = VALUES(encrypted_name), adresse1 = VALUES(adresse1), adresse2 = VALUES(adresse2), code_postal = VALUES(code_postal), ville = VALUES(ville), fk_region = VALUES(fk_region), fk_type = VALUES(fk_type), encrypted_phone = VALUES(encrypted_phone), encrypted_mobile = VALUES(encrypted_mobile), encrypted_email = VALUES(encrypted_email), updated_at = VALUES(updated_at), fk_user_modif = VALUES(fk_user_modif)"; $insertStmt = $this->targetDb->prepare($insertSql); // Insérer chaque entité foreach ($rows as $row) { try { // Chiffrer les données sensibles $encryptedName = ApiService::encryptSearchableData($row['libelle']); $encryptedPhone = !empty($row['tel1']) ? ApiService::encryptData($row['tel1']) : ''; $encryptedMobile = !empty($row['tel2']) ? ApiService::encryptData($row['tel2']) : ''; $encryptedEmail = !empty($row['email']) ? ApiService::encryptSearchableData($row['email']) : ''; $encryptedIban = !empty($row['iban']) ? ApiService::encryptData($row['iban']) : ''; $encryptedBic = !empty($row['bic']) ? ApiService::encryptData($row['bic']) : ''; $insertStmt->execute([ 'id' => $row['rowid'], 'encrypted_name' => $encryptedName, 'adresse1' => $row['adresse1'] ?? '', 'adresse2' => $row['adresse2'] ?? '', 'code_postal' => $row['cp'] ?? '', // cp → code_postal 'ville' => $row['ville'] ?? '', 'fk_region' => $row['fk_region'], 'fk_type' => $row['fk_type'] ?? 1, 'encrypted_phone' => $encryptedPhone, // tel1 'encrypted_mobile' => $encryptedMobile, // tel2 'encrypted_email' => $encryptedEmail, 'gps_lat' => $row['gps_lat'] ?? '', 'gps_lng' => $row['gps_lng'] ?? '', 'chk_stripe' => 0, // Pas dans source 'encrypted_stripe_id' => '', // Pas dans source 'encrypted_iban' => $encryptedIban, 'encrypted_bic' => $encryptedBic, 'chk_demo' => $row['demo'] ?? 0, // demo → chk_demo 'chk_mdp_manuel' => $row['chk_mdp_manuel'] ?? 0, 'chk_username_manuel' => 0, // Pas dans source 'chk_user_delete_pass' => 0, // Pas dans source 'chk_copie_mail_recu' => $row['chk_copie_mail_recu'] ?? 0, 'chk_accept_sms' => $row['chk_accept_sms'] ?? 0, 'chk_lot_actif' => 0, // Pas dans source 'created_at' => null, // Pas date_creat dans source 'fk_user_creat' => null, // Pas dans source 'updated_at' => $row['date_modif'], 'fk_user_modif' => $row['fk_user_modif'] ?? 0, // Peut être NULL 'chk_active' => $row['active'] ?? 1 ]); $success++; } catch (PDOException $e) { $this->log(" ✗ Erreur insertion entité {$row['rowid']}: " . $e->getMessage(), 'ERROR'); $errors++; } } } catch (Exception $e) { $this->log(" ✗ Erreur migration entites: " . $e->getMessage(), 'ERROR'); $errors++; } // Compter les lignes en TARGET après migration $targetCount = $this->countTargetRows('entites', $entityId); $sourceCount = count($rows ?? []); $diff = $targetCount - $sourceCount; $diffStr = $diff >= 0 ? "+$diff" : "$diff"; $this->log(" ✓ Entités migrées avec succès: $success, Erreurs: $errors"); $this->log(" 📊 SOURCE: $sourceCount → TARGET: $targetCount (différence: $diffStr)"); return ['success' => $success, 'errors' => $errors]; } /** * Migration de la table users (avec chiffrement et détection mobile) */ private function migrateUsers($entityId = null) { $success = 0; $errors = 0; try { // Construire la requête de sélection $sql = "SELECT u.rowid, u.fk_entite, u.fk_role, u.fk_titre, u.libelle, u.prenom, u.nom_tournee, u.username, u.userpass, u.telephone, u.mobile, u.email, u.alert_email, u.chk_suivi, u.date_naissance, u.date_embauche, u.date_creat, u.fk_user_creat, u.date_modif, u.fk_user_modif, u.active FROM users u"; if ($entityId) { $sql .= " WHERE u.fk_entite = :entity_id"; } $stmt = $this->sourceDb->prepare($sql); if ($entityId) { $stmt->execute(['entity_id' => $entityId]); } else { $stmt->execute(); } $rows = $stmt->fetchAll(); $this->log(" → " . count($rows) . " user(s) trouvé(s) dans SOURCE"); if (empty($rows)) { $this->log(" → Aucun user à migrer"); return ['success' => 0, 'errors' => 0]; } // Préparer l'insertion $insertSql = "INSERT INTO users ( id, fk_entite, fk_role, fk_titre, encrypted_name, first_name, sect_name, encrypted_user_name, user_pass_hash, encrypted_phone, encrypted_mobile, encrypted_email, chk_alert_email, chk_suivi, date_naissance, date_embauche, created_at, fk_user_creat, updated_at, fk_user_modif, chk_active ) VALUES ( :id, :fk_entite, :fk_role, :fk_titre, :encrypted_name, :first_name, :sect_name, :encrypted_user_name, :user_pass_hash, :encrypted_phone, :encrypted_mobile, :encrypted_email, :chk_alert_email, :chk_suivi, :date_naissance, :date_embauche, :created_at, :fk_user_creat, :updated_at, :fk_user_modif, :chk_active ) ON DUPLICATE KEY UPDATE fk_role = VALUES(fk_role), encrypted_name = VALUES(encrypted_name), first_name = VALUES(first_name), encrypted_phone = VALUES(encrypted_phone), encrypted_mobile = VALUES(encrypted_mobile), encrypted_email = VALUES(encrypted_email), updated_at = VALUES(updated_at), fk_user_modif = VALUES(fk_user_modif)"; $insertStmt = $this->targetDb->prepare($insertSql); // Insérer chaque user foreach ($rows as $row) { try { // Chiffrer les données sensibles $encryptedName = ApiService::encryptSearchableData($row['libelle']); $encryptedUsername = !empty($row['username']) ? ApiService::encryptSearchableData($row['username']) : ''; $encryptedEmail = !empty($row['email']) ? ApiService::encryptSearchableData($row['email']) : ''; // Détection mobile vs fixe basée sur 06/07 $phone = $row['telephone'] ?? ''; $mobile = $row['mobile'] ?? ''; // Si phone commence par 06 ou 07, c'est un mobile if (preg_match('/^0[67]/', $phone)) { if (empty($mobile)) { $mobile = $phone; $phone = ''; } } $encryptedPhone = !empty($phone) ? ApiService::encryptData($phone) : ''; $encryptedMobile = !empty($mobile) ? ApiService::encryptData($mobile) : ''; $insertStmt->execute([ 'id' => $row['rowid'], 'fk_entite' => $row['fk_entite'], 'fk_role' => $row['fk_role'] ?? 1, 'fk_titre' => $row['fk_titre'] ?? 1, 'encrypted_name' => $encryptedName, 'first_name' => $row['prenom'] ?? '', 'sect_name' => $row['nom_tournee'] ?? '', 'encrypted_user_name' => $encryptedUsername, 'user_pass_hash' => $row['userpass'] ?? '', 'encrypted_phone' => $encryptedPhone, 'encrypted_mobile' => $encryptedMobile, 'encrypted_email' => $encryptedEmail, 'chk_alert_email' => $row['alert_email'] ?? 1, 'chk_suivi' => $row['chk_suivi'] ?? 0, 'date_naissance' => $row['date_naissance'], 'date_embauche' => $row['date_embauche'], 'created_at' => $row['date_creat'], 'fk_user_creat' => $row['fk_user_creat'], 'updated_at' => $row['date_modif'], 'fk_user_modif' => $row['fk_user_modif'], 'chk_active' => $row['active'] ?? 1 ]); $success++; } catch (PDOException $e) { $this->log(" ✗ Erreur insertion user {$row['rowid']}: " . $e->getMessage(), 'ERROR'); $errors++; } } } catch (Exception $e) { $this->log(" ✗ Erreur migration users: " . $e->getMessage(), 'ERROR'); $errors++; } // Compter les lignes en TARGET après migration $targetCount = $this->countTargetRows('users', $entityId); $sourceCount = count($rows ?? []); $diff = $targetCount - $sourceCount; $diffStr = $diff >= 0 ? "+$diff" : "$diff"; $this->log(" ✓ Users migrés avec succès: $success, Erreurs: $errors"); $this->log(" 📊 SOURCE: $sourceCount → TARGET: $targetCount (différence: $diffStr)"); return ['success' => $success, 'errors' => $errors]; } /** * Migration de la table operations */ private function migrateOperations($entityId = null) { $success = 0; $errors = 0; try { $sql = "SELECT rowid, fk_entite, libelle, date_deb, date_fin, chk_distinct_sectors, date_creat, fk_user_creat, date_modif, fk_user_modif, active FROM operations"; if ($entityId) { $sql .= " WHERE fk_entite = :entity_id"; } // Ne migrer que les 3 dernières opérations (plus récentes) $sql .= " ORDER BY rowid DESC LIMIT 3"; $stmt = $this->sourceDb->prepare($sql); if ($entityId) { $stmt->execute(['entity_id' => $entityId]); } else { $stmt->execute(); } $rows = $stmt->fetchAll(); $this->log(" → " . count($rows) . " opération(s) trouvée(s) dans SOURCE"); if (empty($rows)) { $this->log(" → Aucune opération à migrer"); return ['success' => 0, 'errors' => 0]; } $insertSql = "INSERT INTO operations ( id, fk_entite, libelle, date_deb, date_fin, chk_distinct_sectors, created_at, fk_user_creat, updated_at, fk_user_modif, chk_active ) VALUES ( :id, :fk_entite, :libelle, :date_deb, :date_fin, :chk_distinct_sectors, :created_at, :fk_user_creat, :updated_at, :fk_user_modif, :chk_active ) ON DUPLICATE KEY UPDATE libelle = VALUES(libelle), date_deb = VALUES(date_deb), date_fin = VALUES(date_fin), updated_at = VALUES(updated_at)"; $insertStmt = $this->targetDb->prepare($insertSql); foreach ($rows as $row) { try { $insertStmt->execute([ 'id' => $row['rowid'], 'fk_entite' => $row['fk_entite'], 'libelle' => $row['libelle'], 'date_deb' => $row['date_deb'], 'date_fin' => $row['date_fin'], 'chk_distinct_sectors' => $row['chk_distinct_sectors'] ?? 0, 'created_at' => $row['date_creat'], 'fk_user_creat' => $row['fk_user_creat'] ?? 0, // 0 au lieu de NULL si vide 'updated_at' => $row['date_modif'], 'fk_user_modif' => $row['fk_user_modif'] ?? 0, // 0 au lieu de NULL si vide 'chk_active' => $row['active'] ?? 1 ]); $success++; } catch (PDOException $e) { $this->log(" ✗ Erreur insertion operation {$row['rowid']}: " . $e->getMessage(), 'ERROR'); $errors++; } } } catch (Exception $e) { $this->log(" ✗ Erreur migration operations: " . $e->getMessage(), 'ERROR'); $errors++; } // Compter les lignes en TARGET après migration $targetCount = $this->countTargetRows('operations', $entityId); $sourceCount = count($rows ?? []); $diff = $targetCount - $sourceCount; $diffStr = $diff >= 0 ? "+$diff" : "$diff"; $this->log(" ✓ Opérations migrées avec succès: $success, Erreurs: $errors"); $this->log(" 📊 SOURCE: $sourceCount → TARGET: $targetCount (différence: $diffStr)"); return ['success' => $success, 'errors' => $errors]; } // Mapping des anciens secteurs vers les nouveaux private $sectorMapping = []; /** * Récupère les IDs des 3 dernières opérations d'une entité */ private function getLastOperationIds($entityId) { $sql = "SELECT rowid FROM operations WHERE fk_entite = ? ORDER BY rowid DESC LIMIT 3"; $stmt = $this->sourceDb->prepare($sql); $stmt->execute([$entityId]); return array_column($stmt->fetchAll(), 'rowid'); } /** * Migration de la table ope_sectors * IMPORTANT: La table source est "sectors" (ancien), la cible est "ope_sectors" (nouveau) */ private function migrateOpeSectors($entityId = null) { $success = 0; $errors = 0; try { // Récupérer les secteurs utilisés depuis ope_users_sectors // Car sectors seul ne contient pas le lien avec les opérations // IMPORTANT: DISTINCT sur (fk_operation, s.rowid) car un secteur peut être réutilisé dans plusieurs opérations $sql = "SELECT DISTINCT ous.fk_operation, s.rowid as old_sector_id, s.libelle, s.sector, s.color, s.date_creat, s.fk_user_creat, s.date_modif, s.fk_user_modif, s.active FROM sectors s INNER JOIN ope_users_sectors ous ON ous.fk_sector = s.rowid"; if ($entityId) { // Récupérer les IDs des 3 dernières opérations $operationIds = $this->getLastOperationIds($entityId); if (empty($operationIds)) { $this->log(" → Aucune opération trouvée pour l'entité"); return ['success' => 0, 'errors' => 0]; } $operationIdsStr = implode(',', $operationIds); $sql .= " INNER JOIN operations o ON ous.fk_operation = o.rowid WHERE o.fk_entite = ? AND o.rowid IN ($operationIdsStr)"; } $sql .= " ORDER BY ous.fk_operation, s.rowid"; $stmt = $this->sourceDb->prepare($sql); if ($entityId) { $stmt->execute([$entityId]); } else { $stmt->execute(); } $rows = $stmt->fetchAll(); $this->log(" → " . count($rows) . " secteur(s) trouvé(s) dans SOURCE"); if (empty($rows)) { $this->log(" → Aucun secteur à migrer"); return ['success' => 0, 'errors' => 0]; } // Préparer l'insertion dans ope_sectors (NOUVEAU ID auto-increment) $insertSql = "INSERT INTO ope_sectors ( fk_operation, fk_old_sector, libelle, sector, color, created_at, fk_user_creat, updated_at, fk_user_modif, chk_active ) VALUES ( :fk_operation, :fk_old_sector, :libelle, :sector, :color, :created_at, :fk_user_creat, :updated_at, :fk_user_modif, :chk_active ) ON DUPLICATE KEY UPDATE libelle = VALUES(libelle), sector = VALUES(sector), color = VALUES(color), updated_at = VALUES(updated_at)"; $insertStmt = $this->targetDb->prepare($insertSql); foreach ($rows as $row) { try { $oldSectorId = $row['old_sector_id']; $operationId = $row['fk_operation']; // Vérifier si ce secteur existe déjà pour cette opération $checkStmt = $this->targetDb->prepare(" SELECT id FROM ope_sectors WHERE fk_operation = ? AND fk_old_sector = ? "); $checkStmt->execute([$operationId, $oldSectorId]); $existing = $checkStmt->fetch(); if ($existing) { // Déjà migré, utiliser l'ID existant $newSectorId = $existing['id']; $this->log(" → Secteur #{$oldSectorId} déjà migré (nouvel ID: {$newSectorId})"); } else { // Insérer le nouveau secteur $insertStmt->execute([ 'fk_operation' => $operationId, 'fk_old_sector' => $oldSectorId, 'libelle' => $row['libelle'], 'sector' => $row['sector'], 'color' => $row['color'] ?? '#4B77BE', 'created_at' => $row['date_creat'], 'fk_user_creat' => $row['fk_user_creat'] ?? 0, // 0 au lieu de NULL si vide 'updated_at' => $row['date_modif'], 'fk_user_modif' => $row['fk_user_modif'] ?? 0, // 0 au lieu de NULL si vide 'chk_active' => $row['active'] ?? 1 ]); // Récupérer le NOUVEAU ID auto-généré $newSectorId = $this->targetDb->lastInsertId(); $this->log(" → Secteur #{$oldSectorId} migré (nouvel ID: {$newSectorId})"); } // Stocker le mapping pour les tables suivantes $mappingKey = $operationId . '_' . $oldSectorId; $this->sectorMapping[$mappingKey] = $newSectorId; $success++; } catch (PDOException $e) { $this->log(" ✗ Erreur insertion secteur {$row['old_sector_id']}: " . $e->getMessage(), 'ERROR'); $errors++; } } $this->log(" → Mapping créé: " . count($this->sectorMapping) . " correspondances"); } catch (Exception $e) { $this->log(" ✗ Erreur migration ope_sectors: " . $e->getMessage(), 'ERROR'); $errors++; } // Compter les lignes en TARGET après migration $targetCount = $this->countTargetRows('ope_sectors', $entityId); $sourceCount = count($rows ?? []); $diff = $targetCount - $sourceCount; $diffStr = $diff >= 0 ? "+$diff" : "$diff"; $this->log(" ✓ Secteurs migrés avec succès: $success, Erreurs: $errors"); $this->log(" 📊 SOURCE: $sourceCount → TARGET: $targetCount (différence: $diffStr)"); return ['success' => $success, 'errors' => $errors]; } /** * Migration de la table sectors_adresses * IMPORTANT: Utilise le mapping créé par migrateOpeSectors() */ private function migrateSectorsAdresses($entityId = null) { $success = 0; $errors = 0; $skipped = 0; try { // Récupérer les adresses avec le lien vers sectors ET operations (via ope_users_sectors) // NOTE: osm_id, osm_name, osm_date_creat n'existent PAS dans SOURCE, valeurs par défaut ajoutées $sql = "SELECT sa.rowid, sa.fk_adresse, sa.fk_sector as old_sector_id, sa.numero, sa.rue_bis, sa.rue, sa.cp, sa.ville, sa.gps_lat, sa.gps_lng, ous.fk_operation FROM sectors_adresses sa INNER JOIN ope_users_sectors ous ON ous.fk_sector = sa.fk_sector"; if ($entityId) { $sql .= " INNER JOIN operations o ON ous.fk_operation = o.rowid WHERE o.fk_entite = :entity_id"; } $sql .= " GROUP BY sa.rowid, ous.fk_operation"; $stmt = $this->sourceDb->prepare($sql); if ($entityId) { $stmt->execute(['entity_id' => $entityId]); } else { $stmt->execute(); } $rows = $stmt->fetchAll(); $this->log(" → " . count($rows) . " adresse(s) de secteur trouvée(s) dans SOURCE"); if (empty($rows)) { $this->log(" → Aucune adresse de secteur à migrer"); return ['success' => 0, 'errors' => 0]; } $insertSql = "INSERT INTO sectors_adresses ( id, fk_adresse, osm_id, fk_sector, osm_name, numero, rue_bis, rue, cp, ville, gps_lat, gps_lng, osm_date_creat, created_at, updated_at ) VALUES ( :id, :fk_adresse, :osm_id, :fk_sector, :osm_name, :numero, :rue_bis, :rue, :cp, :ville, :gps_lat, :gps_lng, :osm_date_creat, :created_at, :updated_at ) ON DUPLICATE KEY UPDATE osm_name = VALUES(osm_name), gps_lat = VALUES(gps_lat), gps_lng = VALUES(gps_lng)"; $insertStmt = $this->targetDb->prepare($insertSql); foreach ($rows as $row) { try { $oldSectorId = $row['old_sector_id']; $operationId = $row['fk_operation']; // Chercher le nouveau ID du secteur dans le mapping $mappingKey = $operationId . '_' . $oldSectorId; if (!isset($this->sectorMapping[$mappingKey])) { $this->log(" ⚠ Adresse {$row['rowid']}: secteur {$oldSectorId} non trouvé dans mapping", 'WARNING'); $skipped++; continue; } $newSectorId = $this->sectorMapping[$mappingKey]; $insertStmt->execute([ 'id' => $row['rowid'], 'fk_adresse' => $row['fk_adresse'], 'osm_id' => 0, // N'existe pas dans SOURCE 'fk_sector' => $newSectorId, // NOUVEAU ID depuis mapping 'osm_name' => '', // N'existe pas dans SOURCE 'numero' => $row['numero'], 'rue_bis' => $row['rue_bis'], 'rue' => $row['rue'], 'cp' => $row['cp'], 'ville' => $row['ville'], 'gps_lat' => $row['gps_lat'], 'gps_lng' => $row['gps_lng'], 'osm_date_creat' => null, // N'existe pas dans SOURCE 'created_at' => null, // N'existe pas dans SOURCE 'updated_at' => null // N'existe pas dans SOURCE ]); $success++; } catch (PDOException $e) { $this->log(" ✗ Erreur insertion sectors_adresses {$row['rowid']}: " . $e->getMessage(), 'ERROR'); $errors++; } } if ($skipped > 0) { $this->log(" → {$skipped} adresses ignorées (secteur non migré)"); } } catch (Exception $e) { $this->log(" ✗ Erreur migration sectors_adresses: " . $e->getMessage(), 'ERROR'); $errors++; } // Compter les lignes en TARGET après migration $targetCount = $this->countTargetRows('sectors_adresses', $entityId); $sourceCount = count($rows ?? []); $diff = $targetCount - $sourceCount; $diffStr = $diff >= 0 ? "+$diff" : "$diff"; $this->log(" ✓ Adresses de secteurs migrées avec succès: $success, Ignorées: $skipped, Erreurs: $errors"); $this->log(" 📊 SOURCE: $sourceCount → TARGET: $targetCount (différence: $diffStr)"); return ['success' => $success, 'errors' => $errors]; } /** * Migration de la table ope_users */ private function migrateOpeUsers($entityId = null) { $success = 0; $errors = 0; try { // Joindre avec users pour récupérer fk_role, prenom, libelle, nom_tournee // IMPORTANT: DISTINCT sur (fk_operation, fk_user) car il peut y avoir des doublons dans SOURCE $sql = "SELECT DISTINCT ou.fk_operation, ou.fk_user, u.fk_role, u.prenom, u.libelle, u.nom_tournee, ou.date_creat, ou.fk_user_creat, ou.date_modif, ou.fk_user_modif, ou.active FROM ope_users ou INNER JOIN users u ON ou.fk_user = u.rowid"; if ($entityId) { $operationIds = $this->getLastOperationIds($entityId); if (empty($operationIds)) { $this->log(" → Aucune opération trouvée pour l'entité"); return ['success' => 0, 'errors' => 0]; } $operationIdsStr = implode(',', $operationIds); $sql .= " WHERE ou.fk_operation IN ($operationIdsStr)"; } $stmt = $this->sourceDb->prepare($sql); $stmt->execute(); $rows = $stmt->fetchAll(); $this->log(" → " . count($rows) . " ope_user(s) trouvé(s) dans SOURCE"); if (empty($rows)) { $this->log(" → Aucun ope_user à migrer"); return ['success' => 0, 'errors' => 0]; } $insertSql = "INSERT INTO ope_users ( fk_operation, fk_user, fk_role, first_name, encrypted_name, sect_name, created_at, fk_user_creat, updated_at, fk_user_modif, chk_active ) VALUES ( :fk_operation, :fk_user, :fk_role, :first_name, :encrypted_name, :sect_name, :created_at, :fk_user_creat, :updated_at, :fk_user_modif, :chk_active ) ON DUPLICATE KEY UPDATE updated_at = VALUES(updated_at)"; $insertStmt = $this->targetDb->prepare($insertSql); foreach ($rows as $row) { try { // Vérifier que fk_user existe dans users de la TARGET $checkUser = $this->targetDb->prepare("SELECT id FROM users WHERE id = ?"); $checkUser->execute([$row['fk_user']]); if (!$checkUser->fetch()) { // User n'existe pas, ignorer cet enregistrement $this->log(" ⚠ OpeUser (op:{$row['fk_operation']}, user:{$row['fk_user']}): user non trouvé, ignoré", 'WARNING'); continue; } // Chiffrer les données sensibles depuis users $encryptedName = !empty($row['libelle']) ? ApiService::encryptSearchableData($row['libelle']) : ''; $insertStmt->execute([ 'fk_operation' => $row['fk_operation'], 'fk_user' => $row['fk_user'], 'fk_role' => $row['fk_role'] ?? 1, 'first_name' => $row['prenom'] ?? '', 'encrypted_name' => $encryptedName, 'sect_name' => $row['nom_tournee'] ?? '', 'created_at' => $row['date_creat'], 'fk_user_creat' => $row['fk_user_creat'], 'updated_at' => $row['date_modif'], 'fk_user_modif' => $row['fk_user_modif'], 'chk_active' => $row['active'] ?? 1 ]); $success++; } catch (PDOException $e) { $this->log(" ✗ Erreur insertion ope_user (op:{$row['fk_operation']}, user:{$row['fk_user']}): " . $e->getMessage(), 'ERROR'); $errors++; } } } catch (Exception $e) { $this->log(" ✗ Erreur migration ope_users: " . $e->getMessage(), 'ERROR'); $errors++; } // Compter les lignes en TARGET après migration $targetCount = $this->countTargetRows('ope_users', $entityId); $sourceCount = count($rows ?? []); $diff = $targetCount - $sourceCount; $diffStr = $diff >= 0 ? "+$diff" : "$diff"; $this->log(" ✓ Ope_users migrés avec succès: $success, Erreurs: $errors"); $this->log(" 📊 SOURCE: $sourceCount → TARGET: $targetCount (différence: $diffStr)"); return ['success' => $success, 'errors' => $errors]; } /** * Migration de la table ope_users_sectors * IMPORTANT: Utilise le mapping créé par migrateOpeSectors() */ private function migrateOpeUsersSectors($entityId = null) { $success = 0; $errors = 0; $skipped = 0; try { // NOTE: date_creat, fk_user_creat, date_modif, fk_user_modif n'existent PAS dans SOURCE $sql = "SELECT ous.rowid, ous.fk_operation, ous.fk_user, ous.fk_sector as old_sector_id, ous.active FROM ope_users_sectors ous"; if ($entityId) { $operationIds = $this->getLastOperationIds($entityId); if (empty($operationIds)) { $this->log(" → Aucune opération trouvée pour l'entité"); return ['success' => 0, 'errors' => 0]; } $operationIdsStr = implode(',', $operationIds); $sql .= " WHERE ous.fk_operation IN ($operationIdsStr)"; } $stmt = $this->sourceDb->prepare($sql); $stmt->execute(); $rows = $stmt->fetchAll(); $this->log(" → " . count($rows) . " ope_users_sector(s) trouvé(s) dans SOURCE"); if (empty($rows)) { $this->log(" → Aucun ope_users_sector à migrer"); return ['success' => 0, 'errors' => 0]; } $insertSql = "INSERT INTO ope_users_sectors ( id, fk_operation, fk_user, fk_sector, created_at, fk_user_creat, updated_at, fk_user_modif, chk_active ) VALUES ( :id, :fk_operation, :fk_user, :fk_sector, :created_at, :fk_user_creat, :updated_at, :fk_user_modif, :chk_active ) ON DUPLICATE KEY UPDATE updated_at = VALUES(updated_at)"; $insertStmt = $this->targetDb->prepare($insertSql); foreach ($rows as $row) { try { $oldSectorId = $row['old_sector_id']; $operationId = $row['fk_operation']; // Chercher le nouveau ID du secteur dans le mapping $mappingKey = $operationId . '_' . $oldSectorId; if (!isset($this->sectorMapping[$mappingKey])) { $this->log(" ⚠ OpeUsersSector {$row['rowid']}: secteur {$oldSectorId} non trouvé dans mapping", 'WARNING'); $skipped++; continue; } // Vérifier que fk_user existe dans users de la TARGET $checkUser = $this->targetDb->prepare("SELECT id FROM users WHERE id = ?"); $checkUser->execute([$row['fk_user']]); if (!$checkUser->fetch()) { // User n'existe pas, ignorer cet enregistrement $this->log(" ⚠ OpeUsersSector {$row['rowid']}: user {$row['fk_user']} non trouvé, ignoré", 'WARNING'); $skipped++; continue; } $newSectorId = $this->sectorMapping[$mappingKey]; $insertStmt->execute([ 'id' => $row['rowid'], 'fk_operation' => $operationId, 'fk_user' => $row['fk_user'], 'fk_sector' => $newSectorId, // NOUVEAU ID depuis mapping 'created_at' => null, // N'existe pas dans SOURCE 'fk_user_creat' => 0, // N'existe pas dans SOURCE - NOT NULL 'updated_at' => null, // N'existe pas dans SOURCE 'fk_user_modif' => 0, // N'existe pas dans SOURCE - NOT NULL 'chk_active' => $row['active'] ?? 1 ]); $success++; } catch (PDOException $e) { $this->log(" ✗ Erreur insertion ope_users_sector {$row['rowid']}: " . $e->getMessage(), 'ERROR'); $errors++; } } if ($skipped > 0) { $this->log(" → {$skipped} associations ignorées (secteur non migré)"); } } catch (Exception $e) { $this->log(" ✗ Erreur migration ope_users_sectors: " . $e->getMessage(), 'ERROR'); $errors++; } // Compter les lignes en TARGET après migration $targetCount = $this->countTargetRows('ope_users_sectors', $entityId); $sourceCount = count($rows ?? []); $diff = $targetCount - $sourceCount; $diffStr = $diff >= 0 ? "+$diff" : "$diff"; $this->log(" ✓ Ope_users_sectors migrés avec succès: $success, Ignorés: $skipped, Erreurs: $errors"); $this->log(" 📊 SOURCE: $sourceCount → TARGET: $targetCount (différence: $diffStr)"); return ['success' => $success, 'errors' => $errors]; } /** * Recherche un secteur par position GPS * 1. Cherche si le point est contenu dans un secteur (ST_Contains) * 2. Sinon, cherche le secteur le plus proche (ST_Distance) * 3. Sinon, retourne le premier secteur de l'opération */ private function findSectorByGPS($operationId, $lat, $lng) { // Si GPS valide, TENTER une recherche géographique (mais ne pas bloquer si ça échoue) if (!empty($lat) && !empty($lng) && $lat != 0 && $lng != 0) { try { // IMPORTANT : Le champ sector est stocké en BLOB, il faut le convertir avec ST_GeomFromWKB // Construire le POINT avec CONCAT pour éviter le binding de paramètres // 1. Chercher si le point est DANS un secteur $sql = "SELECT id FROM ope_sectors WHERE fk_operation = ? AND ST_Contains( ST_GeomFromWKB(sector), ST_GeomFromText(CONCAT('POINT(', ?, ' ', ?, ')'), 4326) ) LIMIT 1"; $stmt = $this->targetDb->prepare($sql); $stmt->execute([$operationId, $lng, $lat]); $result = $stmt->fetch(); if ($result) { return $result['id']; } // 2. Sinon, chercher le secteur le PLUS PROCHE $sql = "SELECT id, ST_Distance( ST_GeomFromWKB(sector), ST_GeomFromText(CONCAT('POINT(', ?, ' ', ?, ')'), 4326) ) as distance FROM ope_sectors WHERE fk_operation = ? AND sector IS NOT NULL ORDER BY distance ASC LIMIT 1"; $stmt = $this->targetDb->prepare($sql); $stmt->execute([$lng, $lat, $operationId]); $result = $stmt->fetch(); if ($result) { return $result['id']; } } catch (Exception $e) { // La recherche GPS a échoué, on continue vers le fallback // (Pas de log pour éviter de polluer avec des milliers de messages) } } // 3. FALLBACK : Premier secteur de l'opération (TOUJOURS exécuté si GPS échoue) try { $sql = "SELECT id FROM ope_sectors WHERE fk_operation = ? LIMIT 1"; $stmt = $this->targetDb->prepare($sql); $stmt->execute([$operationId]); $result = $stmt->fetch(); return $result ? $result['id'] : null; } catch (Exception $e) { $this->log(" ⚠️ Erreur critique recherche secteur fallback: " . $e->getMessage(), 'ERROR'); return null; } } /** * Recherche un utilisateur valide pour un passage * 1. Cherche un user affecté au secteur (via ope_users_sectors) * 2. Sinon, cherche le premier user de l'opération (via ope_users) */ private function findValidUser($operationId, $sectorId) { try { // 1. Chercher un user affecté au secteur $sql = "SELECT fk_user FROM ope_users_sectors WHERE fk_operation = :operation_id AND fk_sector = :sector_id LIMIT 1"; $stmt = $this->targetDb->prepare($sql); $stmt->execute([ 'operation_id' => $operationId, 'sector_id' => $sectorId ]); $result = $stmt->fetch(); if ($result) { return $result['fk_user']; } // 2. FALLBACK : Premier user de l'opération $sql = "SELECT fk_user FROM ope_users WHERE fk_operation = :operation_id LIMIT 1"; $stmt = $this->targetDb->prepare($sql); $stmt->execute(['operation_id' => $operationId]); $result = $stmt->fetch(); return $result ? $result['fk_user'] : null; } catch (Exception $e) { $this->log(" ⚠️ Erreur recherche user valide: " . $e->getMessage(), 'WARNING'); return null; } } /** * Migration de la table ope_pass (avec chiffrement) */ private function migrateOpePass($entityId = null) { $success = 0; $errors = 0; try { $sql = "SELECT p.rowid, p.fk_operation, p.fk_sector, p.fk_user, p.fk_adresse, p.date_eve, p.fk_type, p.numero, p.rue, p.rue_bis, p.ville, p.fk_habitat, p.appt, p.niveau, p.gps_lat, p.gps_lng, p.libelle, p.montant, p.fk_type_reglement, p.remarque, p.email, p.recu, p.email_erreur, p.chk_email_sent, p.phone, p.docremis, p.date_repasser, p.nb_passages, p.chk_gps_maj, p.chk_map_create, p.chk_mobile, p.chk_synchro, p.chk_api_adresse, p.chk_maj_adresse, p.anomalie, p.date_creat, p.fk_user_creat, p.date_modif, p.fk_user_modif, p.active FROM ope_pass p"; if ($entityId) { $operationIds = $this->getLastOperationIds($entityId); if (empty($operationIds)) { $this->log(" → Aucune opération trouvée pour l'entité"); return ['success' => 0, 'errors' => 0]; } $operationIdsStr = implode(',', $operationIds); $sql .= " WHERE p.fk_operation IN ($operationIdsStr)"; } $stmt = $this->sourceDb->prepare($sql); $stmt->execute(); $rows = $stmt->fetchAll(); $this->log(" → " . count($rows) . " passage(s) trouvé(s) dans SOURCE"); if (empty($rows)) { $this->log(" → Aucun passage à migrer"); return ['success' => 0, 'errors' => 0]; } $insertSql = "INSERT INTO ope_pass ( id, fk_operation, fk_sector, fk_user, fk_adresse, passed_at, fk_type, numero, rue, rue_bis, ville, fk_habitat, appt, niveau, residence, gps_lat, gps_lng, encrypted_name, montant, fk_type_reglement, remarque, encrypted_email, nom_recu, date_recu, date_creat_recu, date_sent_recu, email_erreur, chk_email_sent, encrypted_phone, docremis, date_repasser, nb_passages, chk_gps_maj, chk_map_create, chk_mobile, chk_synchro, chk_api_adresse, chk_maj_adresse, anomalie, created_at, fk_user_creat, updated_at, fk_user_modif, chk_active ) VALUES ( :id, :fk_operation, :fk_sector, :fk_user, :fk_adresse, :passed_at, :fk_type, :numero, :rue, :rue_bis, :ville, :fk_habitat, :appt, :niveau, :residence, :gps_lat, :gps_lng, :encrypted_name, :montant, :fk_type_reglement, :remarque, :encrypted_email, :nom_recu, :date_recu, :date_creat_recu, :date_sent_recu, :email_erreur, :chk_email_sent, :encrypted_phone, :docremis, :date_repasser, :nb_passages, :chk_gps_maj, :chk_map_create, :chk_mobile, :chk_synchro, :chk_api_adresse, :chk_maj_adresse, :anomalie, :created_at, :fk_user_creat, :updated_at, :fk_user_modif, :chk_active ) ON DUPLICATE KEY UPDATE encrypted_name = VALUES(encrypted_name), montant = VALUES(montant), encrypted_email = VALUES(encrypted_email), encrypted_phone = VALUES(encrypted_phone), updated_at = VALUES(updated_at)"; $insertStmt = $this->targetDb->prepare($insertSql); // Traiter par lots de 1000 $batchSize = 1000; $total = count($rows); $batches = ceil($total / $batchSize); // Compteurs détaillés $sectorFromMapping = 0; $sectorFromGPS = 0; $sectorFallback = 0; $userOriginal = 0; $userReplaced = 0; for ($i = 0; $i < $batches; $i++) { $offset = $i * $batchSize; $batch = array_slice($rows, $offset, $batchSize); foreach ($batch as $row) { try { // ========== SECTEUR : Garantir un secteur valide ========== $oldSectorId = $row['fk_sector']; $operationId = $row['fk_operation']; $mappingKey = $operationId . '_' . $oldSectorId; $newSectorId = null; // 1. Essayer avec le mapping if (isset($this->sectorMapping[$mappingKey])) { $newSectorId = $this->sectorMapping[$mappingKey]; $sectorFromMapping++; } // 2. Sinon, recherche géographique (avec fallback intégré) else { $newSectorId = $this->findSectorByGPS($operationId, $row['gps_lat'], $row['gps_lng']); if ($newSectorId) { // Si GPS valides, c'est une vraie recherche GPS if (!empty($row['gps_lat']) && !empty($row['gps_lng'])) { $sectorFromGPS++; } else { // Sinon, c'est le fallback (premier secteur) $sectorFallback++; } } } // Si VRAIMENT aucun secteur (opération sans secteur ??) if (!$newSectorId) { $this->log(" ⚠️ Passage #{$row['rowid']} : opération {$operationId} sans secteur, IGNORÉ", 'WARNING'); $errors++; continue; } // ========== UTILISATEUR : Garantir un user valide ========== $fkUser = $row['fk_user']; // Vérifier que fk_user existe dans users de la TARGET if ($fkUser > 0) { $checkUser = $this->targetDb->prepare("SELECT id FROM users WHERE id = ?"); $checkUser->execute([$fkUser]); if ($checkUser->fetch()) { // User valide $userOriginal++; } else { // User n'existe pas, chercher un remplaçant $replacementUser = $this->findValidUser($operationId, $newSectorId); if ($replacementUser) { $fkUser = $replacementUser; $userReplaced++; } else { $this->log(" ⚠️ Passage #{$row['rowid']} : aucun user trouvé pour opération {$operationId}, IGNORÉ", 'WARNING'); $errors++; continue; } } } else { // fk_user = 0 ou NULL, chercher un user valide $replacementUser = $this->findValidUser($operationId, $newSectorId); if ($replacementUser) { $fkUser = $replacementUser; $userReplaced++; } else { $this->log(" ⚠️ Passage #{$row['rowid']} : aucun user trouvé pour opération {$operationId}, IGNORÉ", 'WARNING'); $errors++; continue; } } // Chiffrer les données sensibles $encryptedName = ApiService::encryptSearchableData($row['libelle']); $encryptedEmail = !empty($row['email']) ? ApiService::encryptSearchableData($row['email']) : ''; // Détection mobile vs fixe $phone = $row['phone'] ?? ''; $mobile = ''; if (preg_match('/^0[67]/', $phone)) { $mobile = $phone; $phone = ''; } $encryptedPhone = !empty($mobile) ? ApiService::encryptData($mobile) : ''; // Vérification et correction du type de règlement (comme migrate_ope_pass.php) $fkTypeReglement = $row['fk_type_reglement'] ?? 1; if (!in_array($fkTypeReglement, [1, 2, 3])) { $fkTypeReglement = 4; // Forcer à 4 ("-") si différent de 1, 2 ou 3 } $insertStmt->execute([ 'id' => $row['rowid'], 'fk_operation' => $operationId, 'fk_sector' => $newSectorId, // NOUVEAU ID depuis mapping ou GPS 'fk_user' => $fkUser, // User validé ou remplacé 'fk_adresse' => $row['fk_adresse'], 'passed_at' => $row['date_eve'], 'fk_type' => $row['fk_type'], 'numero' => $row['numero'], 'rue' => $row['rue'], 'rue_bis' => $row['rue_bis'], 'ville' => $row['ville'], 'fk_habitat' => $row['fk_habitat'] ?? 1, 'appt' => $row['appt'], 'niveau' => $row['niveau'], 'residence' => '', 'gps_lat' => $row['gps_lat'], 'gps_lng' => $row['gps_lng'], 'encrypted_name' => $encryptedName, 'montant' => $row['montant'], 'fk_type_reglement' => $fkTypeReglement, 'remarque' => $row['remarque'], 'encrypted_email' => $encryptedEmail, 'nom_recu' => $row['recu'], 'date_recu' => null, 'date_creat_recu' => null, 'date_sent_recu' => null, 'email_erreur' => $row['email_erreur'], 'chk_email_sent' => $row['chk_email_sent'] ?? 0, 'encrypted_phone' => $encryptedPhone, 'docremis' => $row['docremis'] ?? 0, 'date_repasser' => $row['date_repasser'], 'nb_passages' => $row['nb_passages'] ?? 1, 'chk_gps_maj' => $row['chk_gps_maj'] ?? 0, 'chk_map_create' => $row['chk_map_create'] ?? 0, 'chk_mobile' => $row['chk_mobile'] ?? 0, 'chk_synchro' => $row['chk_synchro'] ?? 1, 'chk_api_adresse' => $row['chk_api_adresse'] ?? 0, 'chk_maj_adresse' => $row['chk_maj_adresse'] ?? 0, 'anomalie' => $row['anomalie'] ?? 0, 'created_at' => $row['date_creat'], 'fk_user_creat' => $row['fk_user_creat'], 'updated_at' => $row['date_modif'], 'fk_user_modif' => $row['fk_user_modif'], 'chk_active' => $row['active'] ?? 1 ]); $success++; } catch (PDOException $e) { $this->log(" ✗ Erreur insertion ope_pass {$row['rowid']}: " . $e->getMessage(), 'ERROR'); $errors++; } } // Log progression $processed = min(($i + 1) * $batchSize, $total); $this->log(" → Progression: $processed / $total passages"); } } catch (Exception $e) { $this->log(" ✗ Erreur migration ope_pass: " . $e->getMessage(), 'ERROR'); $errors++; } // Compter les lignes en TARGET après migration $targetCount = $this->countTargetRows('ope_pass', $entityId); $sourceCount = count($rows ?? []); $diff = $targetCount - $sourceCount; $diffStr = $diff >= 0 ? "+$diff" : "$diff"; // Afficher les détails de récupération if (isset($sectorFromMapping) && isset($sectorFromGPS) && isset($sectorFallback)) { $this->log(" 🎯 Secteurs: mapping=$sectorFromMapping | GPS=$sectorFromGPS | fallback=$sectorFallback"); } if (isset($userOriginal) && isset($userReplaced)) { $this->log(" 👤 Users: originaux=$userOriginal | remplacés=$userReplaced"); } $this->log(" ✓ Passages migrés avec succès: $success, Erreurs: $errors"); $this->log(" 📊 SOURCE: $sourceCount → TARGET: $targetCount (différence: $diffStr)"); return ['success' => $success, 'errors' => $errors]; } /** * Migration de la table ope_pass_histo */ private function migrateOpePassHisto($entityId = null) { $success = 0; $errors = 0; try { $sql = "SELECT h.rowid, h.fk_pass, h.date_histo, h.sujet, h.remarque FROM ope_pass_histo h"; if ($entityId) { $operationIds = $this->getLastOperationIds($entityId); if (empty($operationIds)) { $this->log(" → Aucune opération trouvée pour l'entité"); return ['success' => 0, 'errors' => 0]; } $operationIdsStr = implode(',', $operationIds); $sql .= " INNER JOIN ope_pass p ON h.fk_pass = p.rowid WHERE p.fk_operation IN ($operationIdsStr)"; } $stmt = $this->sourceDb->prepare($sql); $stmt->execute(); $rows = $stmt->fetchAll(); $this->log(" → " . count($rows) . " historique(s) de passage trouvé(s) dans SOURCE"); if (empty($rows)) { $this->log(" → Aucun historique de passage à migrer"); return ['success' => 0, 'errors' => 0]; } $insertSql = "INSERT INTO ope_pass_histo ( id, fk_pass, date_histo, sujet, remarque ) VALUES ( :id, :fk_pass, :date_histo, :sujet, :remarque ) ON DUPLICATE KEY UPDATE sujet = VALUES(sujet), remarque = VALUES(remarque)"; $insertStmt = $this->targetDb->prepare($insertSql); foreach ($rows as $row) { try { $insertStmt->execute([ 'id' => $row['rowid'], 'fk_pass' => $row['fk_pass'], 'date_histo' => $row['date_histo'], 'sujet' => $row['sujet'], 'remarque' => $row['remarque'] ]); $success++; } catch (PDOException $e) { $this->log(" ✗ Erreur insertion ope_pass_histo {$row['rowid']}: " . $e->getMessage(), 'ERROR'); $errors++; } } } catch (Exception $e) { $this->log(" ✗ Erreur migration ope_pass_histo: " . $e->getMessage(), 'ERROR'); $errors++; } // Compter les lignes en TARGET après migration $targetCount = $this->countTargetRows('ope_pass_histo', $entityId); $sourceCount = count($rows ?? []); $diff = $targetCount - $sourceCount; $diffStr = $diff >= 0 ? "+$diff" : "$diff"; $this->log(" ✓ Historiques de passages migrés avec succès: $success, Erreurs: $errors"); $this->log(" 📊 SOURCE: $sourceCount → TARGET: $targetCount (différence: $diffStr)"); return ['success' => $success, 'errors' => $errors]; } /** * Migration de la table medias */ private function migrateMedias($entityId = null) { $success = 0; $errors = 0; try { // NOTE: SOURCE a support_rowid (pas support_id), type_fichier (pas file_type), hauteur/largeur (pas original_width/height) // Beaucoup de champs n'existent pas dans SOURCE (fk_entite, fk_operation, file_category, etc.) $sql = "SELECT m.rowid, m.support, m.support_rowid, m.fichier, m.type_fichier, m.description, m.hauteur as original_height, m.largeur as original_width, m.date_creat, m.fk_user_creat, m.date_modif, m.fk_user_modif FROM medias m"; if ($entityId) { $operationIds = $this->getLastOperationIds($entityId); if (empty($operationIds)) { $this->log(" → Aucune opération trouvée pour l'entité"); return ['success' => 0, 'errors' => 0]; } $operationIdsStr = implode(',', $operationIds); // Filtrer les médias liés aux ope_pass des 3 dernières opérations $sql .= " WHERE (m.support = 'ope_pass' AND m.support_rowid IN ( SELECT rowid FROM ope_pass WHERE fk_operation IN ($operationIdsStr) ))"; } $stmt = $this->sourceDb->prepare($sql); $stmt->execute(); $rows = $stmt->fetchAll(); $this->log(" → " . count($rows) . " media(s) trouvé(s) dans SOURCE"); if (empty($rows)) { $this->log(" → Aucun media à migrer"); return ['success' => 0, 'errors' => 0]; } $insertSql = "INSERT INTO medias ( id, support, support_id, fichier, file_type, file_category, file_size, mime_type, original_name, fk_entite, fk_operation, file_path, original_width, original_height, processed_width, processed_height, is_processed, description, created_at, fk_user_creat, updated_at, fk_user_modif ) VALUES ( :id, :support, :support_id, :fichier, :file_type, :file_category, :file_size, :mime_type, :original_name, :fk_entite, :fk_operation, :file_path, :original_width, :original_height, :processed_width, :processed_height, :is_processed, :description, :created_at, :fk_user_creat, :updated_at, :fk_user_modif ) ON DUPLICATE KEY UPDATE file_path = VALUES(file_path), updated_at = VALUES(updated_at)"; $insertStmt = $this->targetDb->prepare($insertSql); foreach ($rows as $row) { try { $insertStmt->execute([ 'id' => $row['rowid'], 'support' => $row['support'], 'support_id' => $row['support_rowid'], // SOURCE utilise support_rowid 'fichier' => $row['fichier'], 'file_type' => $row['type_fichier'], // SOURCE utilise type_fichier 'file_category' => null, // N'existe pas dans SOURCE 'file_size' => null, // N'existe pas dans SOURCE 'mime_type' => null, // N'existe pas dans SOURCE 'original_name' => null, // N'existe pas dans SOURCE 'fk_entite' => null, // N'existe pas dans SOURCE 'fk_operation' => null, // N'existe pas dans SOURCE 'file_path' => null, // N'existe pas dans SOURCE 'original_width' => $row['original_width'], // Mappé depuis largeur 'original_height' => $row['original_height'], // Mappé depuis hauteur 'processed_width' => null, // N'existe pas dans SOURCE 'processed_height' => null, // N'existe pas dans SOURCE 'is_processed' => 0, // N'existe pas dans SOURCE 'description' => $row['description'], 'created_at' => $row['date_creat'], 'fk_user_creat' => $row['fk_user_creat'], 'updated_at' => $row['date_modif'], 'fk_user_modif' => $row['fk_user_modif'] ]); $success++; } catch (PDOException $e) { $this->log(" ✗ Erreur insertion media {$row['rowid']}: " . $e->getMessage(), 'ERROR'); $errors++; } } } catch (Exception $e) { $this->log(" ✗ Erreur migration medias: " . $e->getMessage(), 'ERROR'); $errors++; } // Compter les lignes en TARGET après migration $targetCount = $this->countTargetRows('medias', $entityId); $sourceCount = count($rows ?? []); $diff = $targetCount - $sourceCount; $diffStr = $diff >= 0 ? "+$diff" : "$diff"; $this->log(" ✓ Medias migrés avec succès: $success, Erreurs: $errors"); $this->log(" 📊 SOURCE: $sourceCount → TARGET: $targetCount (différence: $diffStr)"); return ['success' => $success, 'errors' => $errors]; } /** * Logging */ private function log($message, $level = 'INFO') { $timestamp = date('Y-m-d H:i:s'); $logMessage = "[{$timestamp}] [{$level}] {$message}\n"; // Afficher dans la console echo $logMessage; // Écrire dans le fichier de log file_put_contents($this->logFile, $logMessage, FILE_APPEND); } } // === Fonctions globales pour compatibilité avec les scripts existants === /** * Retourne la connexion à la base source (remplace celle de config.php) */ function getSourceConnection() { return $GLOBALS['__MIGRATION_SOURCE_DB'] ?? null; } /** * Retourne la connexion à la base cible (remplace celle de config.php) */ function getTargetConnection() { return $GLOBALS['__MIGRATION_TARGET_DB'] ?? null; } /** * Pas de tunnel SSH nécessaire (bases locales) */ function createSshTunnel() { // Rien à faire, les bases sont locales return true; } /** * Pas de tunnel SSH à fermer */ function closeSshTunnel() { // Rien à faire } /** * Logging simple */ function logOperation($message, $level = 'INFO') { echo "[{$level}] {$message}\n"; } // === Parse des arguments CLI === function parseArguments($argv) { $args = [ 'source-db' => null, 'target-db' => 'pra_geo', 'mode' => 'global', 'entity-id' => null, 'log' => null, 'delete-before' => true, 'help' => false ]; foreach ($argv as $arg) { if (strpos($arg, '--') === 0) { $parts = explode('=', substr($arg, 2), 2); $key = $parts[0]; $value = $parts[1] ?? true; if (array_key_exists($key, $args)) { $args[$key] = $value; } } } return $args; } function showHelp() { echo <<connect()) { exit(1); } $success = $migration->migrate(); exit($success ? 0 : 1);