1<?php 2 3/** 4 * webtrees: online genealogy 5 * Copyright (C) 2021 webtrees development team 6 * This program is free software: you can redistribute it and/or modify 7 * it under the terms of the GNU General Public License as published by 8 * the Free Software Foundation, either version 3 of the License, or 9 * (at your option) any later version. 10 * This program is distributed in the hope that it will be useful, 11 * but WITHOUT ANY WARRANTY; without even the implied warranty of 12 * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the 13 * GNU General Public License for more details. 14 * You should have received a copy of the GNU General Public License 15 * along with this program. If not, see <https://www.gnu.org/licenses/>. 16 */ 17 18declare(strict_types=1); 19 20namespace Fisharebest\Webtrees\Schema; 21 22use Illuminate\Database\Capsule\Manager as DB; 23use Illuminate\Database\Query\Builder; 24use Illuminate\Database\Query\Expression; 25use Illuminate\Database\Schema\Blueprint; 26use PDOException; 27 28/** 29 * Upgrade the database schema from version 44 to version 45. 30 */ 31class Migration44 implements MigrationInterface 32{ 33 /** 34 * Upgrade to to the next version 35 * 36 * @return void 37 */ 38 public function upgrade(): void 39 { 40 // It is simpler to create a new table than to update the existing one. 41 42 if (!DB::schema()->hasTable('place_location')) { 43 DB::schema()->create('place_location', static function (Blueprint $table): void { 44 $table->integer('id', true); 45 $table->integer('parent_id')->nullable(); 46 $table->string('place', 120); 47 $table->double('latitude')->nullable(); 48 $table->double('longitude')->nullable(); 49 50 $table->unique(['parent_id', 'place']); 51 $table->unique(['place', 'parent_id']); 52 53 $table->index(['latitude']); 54 $table->index(['longitude']); 55 }); 56 57 DB::schema()->table('place_location', static function (Blueprint $table): void { 58 $table->foreign(['parent_id']) 59 ->references(['id']) 60 ->on('place_location') 61 ->onDelete('CASCADE') 62 ->onUpdate('CASCADE'); 63 }); 64 } 65 66 if (DB::schema()->hasTable('placelocation')) { 67 DB::table('placelocation') 68 ->where('pl_lati', '=', '') 69 ->orWhere('pl_long', '=', '') 70 ->update([ 71 'pl_lati' => null, 72 'pl_long' => null, 73 ]); 74 75 // Missing/invalid parents? Move them to the top level 76 DB::table('placelocation AS pl1') 77 ->leftJoin('placelocation AS pl2', 'pl1.pl_parent_id', '=', 'pl2.pl_id') 78 ->whereNull('pl2.pl_id') 79 ->update([ 80 'pl1.pl_parent_id' => 0, 81 ]); 82 83 // Remove invalid values. 84 if (DB::connection()->getDriverName() === 'mysql') { 85 DB::table('placelocation') 86 ->where('pl_lati', 'NOT REGEXP', '[^NS][0-9]+[.]?[0-9]*$') 87 ->orWhere('pl_long', 'NOT REGEXP', '[^EW][0-9]+[.]?[0-9]*$') 88 ->update([ 89 'pl_lati' => '', 90 'pl_long' => '', 91 ]); 92 } 93 94 DB::table('placelocation') 95 ->update([ 96 'pl_place' => new Expression('SUBSTR(pl_place, 1, 60)'), 97 ]); 98 99 // The lack of unique key constraints means that there may be duplicates... 100 while (true) { 101 // Two places with the same name and parent... 102 $row = DB::table('placelocation') 103 ->select([ 104 new Expression('MIN(pl_id) AS min'), 105 new Expression('MAX(pl_id) AS max'), 106 ]) 107 ->groupBy(['pl_parent_id', 'pl_place']) 108 ->having(new Expression('COUNT(*)'), '>', '1') 109 ->first(); 110 111 if ($row === null) { 112 break; 113 } 114 115 // ...move children to the first 116 DB::table('placelocation') 117 ->where('pl_parent_id', '=', $row->max) 118 ->update(['pl_parent_id' => $row->min]); 119 120 // ...delete the second 121 DB::table('placelocation') 122 ->where('pl_id', '=', $row->max) 123 ->delete(); 124 } 125 126 // This is the SQL standard. It works with Postgres, Sqlite and MySQL 8 127 $select1 = DB::table('placelocation') 128 ->leftJoin('place_location', 'id', '=', 'pl_id') 129 ->whereNull('id') 130 ->orderBy('pl_level') 131 ->orderBy('pl_id') 132 ->select([ 133 'pl_id', 134 new Expression('CASE pl_parent_id WHEN 0 THEN NULL ELSE pl_parent_id END'), 135 'pl_place', 136 new Expression("CAST(REPLACE(REPLACE(pl_lati, 'S', '-'), 'N', '') AS FLOAT)"), 137 new Expression("CAST(REPLACE(REPLACE(pl_long, 'W', '-'), 'E', '') AS FLOAT)"), 138 ]); 139 140 // This works for MySQL 5.7 and lower, which cannot cast to FLOAT 141 $select2 = DB::table('placelocation') 142 ->leftJoin('place_location', 'id', '=', 'pl_id') 143 ->whereNull('id') 144 ->orderBy('pl_level') 145 ->orderBy('pl_id') 146 ->select([ 147 'pl_id', 148 new Expression('CASE pl_parent_id WHEN 0 THEN NULL ELSE pl_parent_id END'), 149 'pl_place', 150 new Expression("REPLACE(REPLACE(pl_lati, 'S', '-'), 'N', '')"), 151 new Expression("REPLACE(REPLACE(pl_long, 'W', '-'), 'E', '')"), 152 ]); 153 154 try { 155 DB::table('place_location') 156 ->insertUsing(['id', 'parent_id', 'place', 'latitude', 'longitude'], $select1); 157 } catch (PDOException $ex) { 158 DB::table('place_location') 159 ->insertUsing(['id', 'parent_id', 'place', 'latitude', 'longitude'], $select2); 160 } 161 162 DB::schema()->drop('placelocation'); 163 } 164 165 // Earlier versions of webtrees used 0 and NULL interchangeably. 166 // Assume 0 at the country-level and NULL at lower levels. 167 DB::table('place_location') 168 ->whereNotNull('parent_id') 169 ->where('latitude', '=', 0) 170 ->where('longitude', '=', 0) 171 ->update([ 172 'latitude' => null, 173 'longitude' => null, 174 ]); 175 } 176} 177