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; 23b9c072a3SGreg Roachuse Illuminate\Database\Query\Builder; 249a9dfcf7SGreg Roachuse Illuminate\Database\Query\Expression; 259a9dfcf7SGreg Roachuse Illuminate\Database\Schema\Blueprint; 268155639aSGreg Roachuse PDOException; 279a9dfcf7SGreg Roach 289a9dfcf7SGreg Roach/** 299a9dfcf7SGreg Roach * Upgrade the database schema from version 44 to version 45. 309a9dfcf7SGreg Roach */ 319a9dfcf7SGreg Roachclass Migration44 implements MigrationInterface 329a9dfcf7SGreg Roach{ 339a9dfcf7SGreg Roach /** 349a9dfcf7SGreg Roach * Upgrade to to the next version 359a9dfcf7SGreg Roach * 369a9dfcf7SGreg Roach * @return void 379a9dfcf7SGreg Roach */ 389a9dfcf7SGreg Roach public function upgrade(): void 399a9dfcf7SGreg Roach { 4090949315SGreg Roach // It is simpler to create a new table than to update the existing one. 4190949315SGreg Roach 4290949315SGreg Roach if (!DB::schema()->hasTable('place_location')) { 4390949315SGreg Roach DB::schema()->create('place_location', static function (Blueprint $table): void { 4490949315SGreg Roach $table->integer('id', true); 4590949315SGreg Roach $table->integer('parent_id')->nullable(); 4690949315SGreg Roach $table->string('place', 120); 4790949315SGreg Roach $table->double('latitude')->nullable(); 4890949315SGreg Roach $table->double('longitude')->nullable(); 4990949315SGreg Roach 5090949315SGreg Roach $table->unique(['parent_id', 'place']); 5190949315SGreg Roach $table->unique(['place', 'parent_id']); 5290949315SGreg Roach 5390949315SGreg Roach $table->index(['latitude']); 5490949315SGreg Roach $table->index(['longitude']); 5590949315SGreg Roach }); 5690949315SGreg Roach 5790949315SGreg Roach DB::schema()->table('place_location', static function (Blueprint $table): void { 5890949315SGreg Roach $table->foreign(['parent_id']) 5990949315SGreg Roach ->references(['id']) 6090949315SGreg Roach ->on('place_location') 6190949315SGreg Roach ->onDelete('CASCADE') 6290949315SGreg Roach ->onUpdate('CASCADE'); 639a9dfcf7SGreg Roach }); 649a9dfcf7SGreg Roach } 659a9dfcf7SGreg Roach 6690949315SGreg Roach if (DB::schema()->hasTable('placelocation')) { 679a9dfcf7SGreg Roach DB::table('placelocation') 6890949315SGreg Roach ->where('pl_lati', '=', '') 6990949315SGreg Roach ->orWhere('pl_long', '=', '') 7090949315SGreg Roach ->update([ 7190949315SGreg Roach 'pl_lati' => null, 7290949315SGreg Roach 'pl_long' => null, 7390949315SGreg Roach ]); 749a9dfcf7SGreg Roach 7529395507SGreg Roach // Missing/invalid parents? Move them to the top level 7629395507SGreg Roach DB::table('placelocation AS pl1') 7729395507SGreg Roach ->leftJoin('placelocation AS pl2', 'pl1.pl_parent_id', '=', 'pl2.pl_id') 7829395507SGreg Roach ->whereNull('pl2.pl_id') 7929395507SGreg Roach ->update([ 8029395507SGreg Roach 'pl1.pl_parent_id' => 0, 8129395507SGreg Roach ]); 8229395507SGreg Roach 83b9c072a3SGreg Roach // Remove invalid values. 847f27675cSGreg Roach if (DB::connection()->getDriverName() === 'mysql') { 85b9c072a3SGreg Roach DB::table('placelocation') 867f27675cSGreg Roach ->where('pl_lati', 'NOT REGEXP', '[^NS][0-9]+[.]?[0-9]*$') 877f27675cSGreg Roach ->orWhere('pl_long', 'NOT REGEXP', '[^EW][0-9]+[.]?[0-9]*$') 88b9c072a3SGreg Roach ->update([ 89b9c072a3SGreg Roach 'pl_lati' => '', 90b9c072a3SGreg Roach 'pl_long' => '', 91b9c072a3SGreg Roach ]); 927f27675cSGreg Roach } 93b9c072a3SGreg Roach 947f27675cSGreg Roach DB::table('placelocation') 957f27675cSGreg Roach ->update([ 96*5bc6120aSGreg Roach 'pl_place' => new Expression('SUBSTR(pl_place, 1, 120)'), 977f27675cSGreg Roach ]); 98b9c072a3SGreg Roach 99663dd9d8SGreg Roach // The lack of unique key constraints means that there may be duplicates... 100663dd9d8SGreg Roach while (true) { 101663dd9d8SGreg Roach // Two places with the same name and parent... 102663dd9d8SGreg Roach $row = DB::table('placelocation') 103663dd9d8SGreg Roach ->select([ 104663dd9d8SGreg Roach new Expression('MIN(pl_id) AS min'), 105663dd9d8SGreg Roach new Expression('MAX(pl_id) AS max'), 106663dd9d8SGreg Roach ]) 107663dd9d8SGreg Roach ->groupBy(['pl_parent_id', 'pl_place']) 108663dd9d8SGreg Roach ->having(new Expression('COUNT(*)'), '>', '1') 109663dd9d8SGreg Roach ->first(); 110663dd9d8SGreg Roach 111663dd9d8SGreg Roach if ($row === null) { 112663dd9d8SGreg Roach break; 113663dd9d8SGreg Roach } 114663dd9d8SGreg Roach 115663dd9d8SGreg Roach // ...move children to the first 116663dd9d8SGreg Roach DB::table('placelocation') 117663dd9d8SGreg Roach ->where('pl_parent_id', '=', $row->max) 118663dd9d8SGreg Roach ->update(['pl_parent_id' => $row->min]); 119663dd9d8SGreg Roach 120663dd9d8SGreg Roach // ...delete the second 121663dd9d8SGreg Roach DB::table('placelocation') 122663dd9d8SGreg Roach ->where('pl_id', '=', $row->max) 123663dd9d8SGreg Roach ->delete(); 124663dd9d8SGreg Roach } 125663dd9d8SGreg Roach 1268155639aSGreg Roach // This is the SQL standard. It works with Postgres, Sqlite and MySQL 8 1278155639aSGreg Roach $select1 = DB::table('placelocation') 12890949315SGreg Roach ->leftJoin('place_location', 'id', '=', 'pl_id') 12990949315SGreg Roach ->whereNull('id') 13060e0106fSGreg Roach ->orderBy('pl_level') 13190949315SGreg Roach ->orderBy('pl_id') 13290949315SGreg Roach ->select([ 13390949315SGreg Roach 'pl_id', 13490949315SGreg Roach new Expression('CASE pl_parent_id WHEN 0 THEN NULL ELSE pl_parent_id END'), 13590949315SGreg Roach 'pl_place', 136cec4277eSGreg Roach new Expression("CAST(REPLACE(REPLACE(pl_lati, 'S', '-'), 'N', '') AS FLOAT)"), 137cec4277eSGreg Roach new Expression("CAST(REPLACE(REPLACE(pl_long, 'W', '-'), 'E', '') AS FLOAT)"), 13890949315SGreg Roach ]); 1399a9dfcf7SGreg Roach 1408155639aSGreg Roach // This works for MySQL 5.7 and lower, which cannot cast to FLOAT 1418155639aSGreg Roach $select2 = DB::table('placelocation') 1428155639aSGreg Roach ->leftJoin('place_location', 'id', '=', 'pl_id') 1438155639aSGreg Roach ->whereNull('id') 14460e0106fSGreg Roach ->orderBy('pl_level') 1458155639aSGreg Roach ->orderBy('pl_id') 1468155639aSGreg Roach ->select([ 1478155639aSGreg Roach 'pl_id', 1488155639aSGreg Roach new Expression('CASE pl_parent_id WHEN 0 THEN NULL ELSE pl_parent_id END'), 1498155639aSGreg Roach 'pl_place', 1508155639aSGreg Roach new Expression("REPLACE(REPLACE(pl_lati, 'S', '-'), 'N', '')"), 1518155639aSGreg Roach new Expression("REPLACE(REPLACE(pl_long, 'W', '-'), 'E', '')"), 1528155639aSGreg Roach ]); 1538155639aSGreg Roach 1548155639aSGreg Roach try { 15590949315SGreg Roach DB::table('place_location') 1568155639aSGreg Roach ->insertUsing(['id', 'parent_id', 'place', 'latitude', 'longitude'], $select1); 1578155639aSGreg Roach } catch (PDOException $ex) { 1588155639aSGreg Roach DB::table('place_location') 1598155639aSGreg Roach ->insertUsing(['id', 'parent_id', 'place', 'latitude', 'longitude'], $select2); 1608155639aSGreg Roach } 1619a9dfcf7SGreg Roach 16290949315SGreg Roach DB::schema()->drop('placelocation'); 16390949315SGreg Roach } 16490949315SGreg Roach 16590949315SGreg Roach // Earlier versions of webtrees used 0 and NULL interchangeably. 16690949315SGreg Roach // Assume 0 at the country-level and NULL at lower levels. 16790949315SGreg Roach DB::table('place_location') 16890949315SGreg Roach ->whereNotNull('parent_id') 16990949315SGreg Roach ->where('latitude', '=', 0) 17090949315SGreg Roach ->where('longitude', '=', 0) 17190949315SGreg Roach ->update([ 17290949315SGreg Roach 'latitude' => null, 17390949315SGreg Roach 'longitude' => null, 17490949315SGreg Roach ]); 1759a9dfcf7SGreg Roach } 1769a9dfcf7SGreg Roach} 177