19a9dfcf7SGreg Roach<?php 29a9dfcf7SGreg Roach 39a9dfcf7SGreg Roach/** 49a9dfcf7SGreg Roach * webtrees: online genealogy 590949315SGreg Roach * Copyright (C) 2021 webtrees development team 69a9dfcf7SGreg Roach * This program is free software: you can redistribute it and/or modify 79a9dfcf7SGreg Roach * it under the terms of the GNU General Public License as published by 89a9dfcf7SGreg Roach * the Free Software Foundation, either version 3 of the License, or 99a9dfcf7SGreg Roach * (at your option) any later version. 109a9dfcf7SGreg Roach * This program is distributed in the hope that it will be useful, 119a9dfcf7SGreg Roach * but WITHOUT ANY WARRANTY; without even the implied warranty of 129a9dfcf7SGreg Roach * MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the 139a9dfcf7SGreg Roach * GNU General Public License for more details. 149a9dfcf7SGreg Roach * You should have received a copy of the GNU General Public License 1589f7189bSGreg Roach * along with this program. If not, see <https://www.gnu.org/licenses/>. 169a9dfcf7SGreg Roach */ 179a9dfcf7SGreg Roach 189a9dfcf7SGreg Roachdeclare(strict_types=1); 199a9dfcf7SGreg Roach 209a9dfcf7SGreg Roachnamespace Fisharebest\Webtrees\Schema; 219a9dfcf7SGreg Roach 229a9dfcf7SGreg Roachuse Illuminate\Database\Capsule\Manager as DB; 239a9dfcf7SGreg Roachuse Illuminate\Database\Query\Expression; 249a9dfcf7SGreg Roachuse Illuminate\Database\Schema\Blueprint; 258155639aSGreg Roachuse PDOException; 269a9dfcf7SGreg Roach 279a9dfcf7SGreg Roach/** 289a9dfcf7SGreg Roach * Upgrade the database schema from version 44 to version 45. 299a9dfcf7SGreg Roach */ 309a9dfcf7SGreg Roachclass Migration44 implements MigrationInterface 319a9dfcf7SGreg Roach{ 329a9dfcf7SGreg Roach /** 33*d9efec4aSGreg Roach * Upgrade to the next version 349a9dfcf7SGreg Roach * 359a9dfcf7SGreg Roach * @return void 369a9dfcf7SGreg Roach */ 379a9dfcf7SGreg Roach public function upgrade(): void 389a9dfcf7SGreg Roach { 3990949315SGreg Roach // It is simpler to create a new table than to update the existing one. 4090949315SGreg Roach 4190949315SGreg Roach if (!DB::schema()->hasTable('place_location')) { 4290949315SGreg Roach DB::schema()->create('place_location', static function (Blueprint $table): void { 4390949315SGreg Roach $table->integer('id', true); 4490949315SGreg Roach $table->integer('parent_id')->nullable(); 4590949315SGreg Roach $table->string('place', 120); 4690949315SGreg Roach $table->double('latitude')->nullable(); 4790949315SGreg Roach $table->double('longitude')->nullable(); 4890949315SGreg Roach 4990949315SGreg Roach $table->unique(['parent_id', 'place']); 5090949315SGreg Roach $table->unique(['place', 'parent_id']); 5190949315SGreg Roach 5290949315SGreg Roach $table->index(['latitude']); 5390949315SGreg Roach $table->index(['longitude']); 5490949315SGreg Roach }); 5590949315SGreg Roach 5690949315SGreg Roach DB::schema()->table('place_location', static function (Blueprint $table): void { 5790949315SGreg Roach $table->foreign(['parent_id']) 5890949315SGreg Roach ->references(['id']) 5990949315SGreg Roach ->on('place_location') 6090949315SGreg Roach ->onDelete('CASCADE') 6190949315SGreg Roach ->onUpdate('CASCADE'); 629a9dfcf7SGreg Roach }); 639a9dfcf7SGreg Roach } 649a9dfcf7SGreg Roach 6590949315SGreg Roach if (DB::schema()->hasTable('placelocation')) { 669a9dfcf7SGreg Roach DB::table('placelocation') 6790949315SGreg Roach ->where('pl_lati', '=', '') 6890949315SGreg Roach ->orWhere('pl_long', '=', '') 6990949315SGreg Roach ->update([ 7090949315SGreg Roach 'pl_lati' => null, 7190949315SGreg Roach 'pl_long' => null, 7290949315SGreg Roach ]); 739a9dfcf7SGreg Roach 7429395507SGreg Roach // Missing/invalid parents? Move them to the top level 7529395507SGreg Roach DB::table('placelocation AS pl1') 7629395507SGreg Roach ->leftJoin('placelocation AS pl2', 'pl1.pl_parent_id', '=', 'pl2.pl_id') 7729395507SGreg Roach ->whereNull('pl2.pl_id') 7829395507SGreg Roach ->update([ 7929395507SGreg Roach 'pl1.pl_parent_id' => 0, 8029395507SGreg Roach ]); 8129395507SGreg Roach 82b9c072a3SGreg Roach // Remove invalid values. 837f27675cSGreg Roach if (DB::connection()->getDriverName() === 'mysql') { 84b9c072a3SGreg Roach DB::table('placelocation') 85aa27872dSGreg Roach ->where('pl_lati', 'NOT REGEXP', '^[NS][0-9]+[.]?[0-9]*$') 86aa27872dSGreg Roach ->orWhere('pl_long', 'NOT REGEXP', '^[EW][0-9]+[.]?[0-9]*$') 87b9c072a3SGreg Roach ->update([ 88aa27872dSGreg Roach 'pl_lati' => null, 89aa27872dSGreg Roach 'pl_long' => null, 90b9c072a3SGreg Roach ]); 917f27675cSGreg Roach } 92b9c072a3SGreg Roach 937a505637SGreg Roach // The existing data may have placenames that only differ after the first 120 chars. 947a505637SGreg Roach // Need to remove the constraint before we truncate/merge them. 957a505637SGreg Roach try { 967a505637SGreg Roach DB::schema()->table('placelocation', static function (Blueprint $table): void { 9720338eabSGreg Roach $table->dropUnique(['pl_parent_id', 'pl_place']); 987a505637SGreg Roach }); 997a505637SGreg Roach } catch (PDOException $ex) { 1007a505637SGreg Roach // Already deleted, or does not exist; 1017a505637SGreg Roach } 1027a505637SGreg Roach 1037f27675cSGreg Roach DB::table('placelocation') 1047f27675cSGreg Roach ->update([ 1055bc6120aSGreg Roach 'pl_place' => new Expression('SUBSTR(pl_place, 1, 120)'), 1067f27675cSGreg Roach ]); 107b9c072a3SGreg Roach 108663dd9d8SGreg Roach // The lack of unique key constraints means that there may be duplicates... 109663dd9d8SGreg Roach while (true) { 110663dd9d8SGreg Roach // Two places with the same name and parent... 111663dd9d8SGreg Roach $row = DB::table('placelocation') 112663dd9d8SGreg Roach ->select([ 113663dd9d8SGreg Roach new Expression('MIN(pl_id) AS min'), 114663dd9d8SGreg Roach new Expression('MAX(pl_id) AS max'), 115663dd9d8SGreg Roach ]) 116663dd9d8SGreg Roach ->groupBy(['pl_parent_id', 'pl_place']) 117663dd9d8SGreg Roach ->having(new Expression('COUNT(*)'), '>', '1') 118663dd9d8SGreg Roach ->first(); 119663dd9d8SGreg Roach 120663dd9d8SGreg Roach if ($row === null) { 121663dd9d8SGreg Roach break; 122663dd9d8SGreg Roach } 123663dd9d8SGreg Roach 124663dd9d8SGreg Roach // ...move children to the first 125663dd9d8SGreg Roach DB::table('placelocation') 126663dd9d8SGreg Roach ->where('pl_parent_id', '=', $row->max) 127663dd9d8SGreg Roach ->update(['pl_parent_id' => $row->min]); 128663dd9d8SGreg Roach 129663dd9d8SGreg Roach // ...delete the second 130663dd9d8SGreg Roach DB::table('placelocation') 131663dd9d8SGreg Roach ->where('pl_id', '=', $row->max) 132663dd9d8SGreg Roach ->delete(); 133663dd9d8SGreg Roach } 134663dd9d8SGreg Roach 1358155639aSGreg Roach // This is the SQL standard. It works with Postgres, Sqlite and MySQL 8 1368155639aSGreg Roach $select1 = DB::table('placelocation') 13790949315SGreg Roach ->leftJoin('place_location', 'id', '=', 'pl_id') 13890949315SGreg Roach ->whereNull('id') 13960e0106fSGreg Roach ->orderBy('pl_level') 14090949315SGreg Roach ->orderBy('pl_id') 14190949315SGreg Roach ->select([ 14290949315SGreg Roach 'pl_id', 14390949315SGreg Roach new Expression('CASE pl_parent_id WHEN 0 THEN NULL ELSE pl_parent_id END'), 14490949315SGreg Roach 'pl_place', 145cec4277eSGreg Roach new Expression("CAST(REPLACE(REPLACE(pl_lati, 'S', '-'), 'N', '') AS FLOAT)"), 146cec4277eSGreg Roach new Expression("CAST(REPLACE(REPLACE(pl_long, 'W', '-'), 'E', '') AS FLOAT)"), 14790949315SGreg Roach ]); 1489a9dfcf7SGreg Roach 1498155639aSGreg Roach // This works for MySQL 5.7 and lower, which cannot cast to FLOAT 1508155639aSGreg Roach $select2 = DB::table('placelocation') 1518155639aSGreg Roach ->leftJoin('place_location', 'id', '=', 'pl_id') 1528155639aSGreg Roach ->whereNull('id') 15360e0106fSGreg Roach ->orderBy('pl_level') 1548155639aSGreg Roach ->orderBy('pl_id') 1558155639aSGreg Roach ->select([ 1568155639aSGreg Roach 'pl_id', 1578155639aSGreg Roach new Expression('CASE pl_parent_id WHEN 0 THEN NULL ELSE pl_parent_id END'), 1588155639aSGreg Roach 'pl_place', 1598155639aSGreg Roach new Expression("REPLACE(REPLACE(pl_lati, 'S', '-'), 'N', '')"), 1608155639aSGreg Roach new Expression("REPLACE(REPLACE(pl_long, 'W', '-'), 'E', '')"), 1618155639aSGreg Roach ]); 1628155639aSGreg Roach 1638155639aSGreg Roach try { 16490949315SGreg Roach DB::table('place_location') 1658155639aSGreg Roach ->insertUsing(['id', 'parent_id', 'place', 'latitude', 'longitude'], $select1); 1668155639aSGreg Roach } catch (PDOException $ex) { 1678155639aSGreg Roach DB::table('place_location') 1688155639aSGreg Roach ->insertUsing(['id', 'parent_id', 'place', 'latitude', 'longitude'], $select2); 1698155639aSGreg Roach } 1709a9dfcf7SGreg Roach 17190949315SGreg Roach DB::schema()->drop('placelocation'); 17290949315SGreg Roach } 17390949315SGreg Roach 17490949315SGreg Roach // Earlier versions of webtrees used 0 and NULL interchangeably. 17590949315SGreg Roach // Assume 0 at the country-level and NULL at lower levels. 17690949315SGreg Roach DB::table('place_location') 17790949315SGreg Roach ->whereNotNull('parent_id') 17890949315SGreg Roach ->where('latitude', '=', 0) 17990949315SGreg Roach ->where('longitude', '=', 0) 18090949315SGreg Roach ->update([ 18190949315SGreg Roach 'latitude' => null, 18290949315SGreg Roach 'longitude' => null, 18390949315SGreg Roach ]); 1849a9dfcf7SGreg Roach } 1859a9dfcf7SGreg Roach} 186