xref: /webtrees/app/Schema/Migration44.php (revision d11be7027e34e3121be11cc025421873364403f9)
19a9dfcf7SGreg Roach<?php
29a9dfcf7SGreg Roach
39a9dfcf7SGreg Roach/**
49a9dfcf7SGreg Roach * webtrees: online genealogy
5*d11be702SGreg Roach * Copyright (C) 2023 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    /**
33d9efec4aSGreg 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
566ed487d2SGreg Roach            // SQL-server cannot cascade-delete/update on self-relations.
576ed487d2SGreg Roach            // Users will need to delete all child locations before deleting the parent.
586ed487d2SGreg Roach            if (DB::connection()->getDriverName() === 'sqlsrv') {
5968bce89dSGreg Roach                // SQL-Server doesn't support 'RESTRICT'
6068bce89dSGreg Roach                $action = 'NO ACTION';
616ed487d2SGreg Roach            } else {
626ed487d2SGreg Roach                $action = 'CASCADE';
636ed487d2SGreg Roach            }
646ed487d2SGreg Roach
656ed487d2SGreg Roach            DB::schema()->table('place_location', static function (Blueprint $table) use ($action): void {
6690949315SGreg Roach                $table->foreign(['parent_id'])
6790949315SGreg Roach                    ->references(['id'])
6890949315SGreg Roach                    ->on('place_location')
696ed487d2SGreg Roach                    ->onDelete($action)
706ed487d2SGreg Roach                    ->onUpdate($action);
719a9dfcf7SGreg Roach            });
729a9dfcf7SGreg Roach        }
739a9dfcf7SGreg Roach
74b344f1f7SGreg Roach        // This table should only exist if we are upgrading an old installation, which would have been
75b344f1f7SGreg Roach        // created with MySQL.  Therefore we can safely use MySQL-specific SQL.
7690949315SGreg Roach        if (DB::schema()->hasTable('placelocation')) {
77b344f1f7SGreg Roach            if (DB::connection()->getDriverName() === 'mysql') {
789a9dfcf7SGreg Roach                DB::table('placelocation')
7990949315SGreg Roach                    ->where('pl_lati', '=', '')
8090949315SGreg Roach                    ->orWhere('pl_long', '=', '')
8190949315SGreg Roach                    ->update([
8290949315SGreg Roach                        'pl_lati' => null,
8390949315SGreg Roach                        'pl_long' => null,
8490949315SGreg Roach                    ]);
859a9dfcf7SGreg Roach
8629395507SGreg Roach                // Missing/invalid parents?  Move them to the top level
8729395507SGreg Roach                DB::table('placelocation AS pl1')
8829395507SGreg Roach                    ->leftJoin('placelocation AS pl2', 'pl1.pl_parent_id', '=', 'pl2.pl_id')
8929395507SGreg Roach                    ->whereNull('pl2.pl_id')
9029395507SGreg Roach                    ->update([
9129395507SGreg Roach                        'pl1.pl_parent_id' => 0,
9229395507SGreg Roach                    ]);
9329395507SGreg Roach
94b9c072a3SGreg Roach                // Remove invalid values.
95b9c072a3SGreg Roach                DB::table('placelocation')
96aa27872dSGreg Roach                    ->where('pl_lati', 'NOT REGEXP', '^[NS][0-9]+[.]?[0-9]*$')
97aa27872dSGreg Roach                    ->orWhere('pl_long', 'NOT REGEXP', '^[EW][0-9]+[.]?[0-9]*$')
98b9c072a3SGreg Roach                    ->update([
99aa27872dSGreg Roach                        'pl_lati' => null,
100aa27872dSGreg Roach                        'pl_long' => null,
101b9c072a3SGreg Roach                    ]);
102b9c072a3SGreg Roach
1037a505637SGreg Roach                // The existing data may have placenames that only differ after the first 120 chars.
1047a505637SGreg Roach                // Need to remove the constraint before we truncate/merge them.
1057a505637SGreg Roach                try {
1067a505637SGreg Roach                    DB::schema()->table('placelocation', static function (Blueprint $table): void {
10720338eabSGreg Roach                        $table->dropUnique(['pl_parent_id', 'pl_place']);
1087a505637SGreg Roach                    });
10928d026adSGreg Roach                } catch (PDOException) {
1107a505637SGreg Roach                    // Already deleted, or does not exist;
1117a505637SGreg Roach                }
1127a505637SGreg Roach
1137f27675cSGreg Roach                DB::table('placelocation')
1147f27675cSGreg Roach                    ->update([
115b344f1f7SGreg Roach                        'pl_place' => new Expression('SUBSTRING(pl_place, 1, 120)'),
1167f27675cSGreg Roach                    ]);
117b9c072a3SGreg Roach
118663dd9d8SGreg Roach                // The lack of unique key constraints means that there may be duplicates...
119663dd9d8SGreg Roach                while (true) {
120663dd9d8SGreg Roach                    // Two places with the same name and parent...
121663dd9d8SGreg Roach                    $row = DB::table('placelocation')
122663dd9d8SGreg Roach                        ->select([
123663dd9d8SGreg Roach                            new Expression('MIN(pl_id) AS min'),
124663dd9d8SGreg Roach                            new Expression('MAX(pl_id) AS max'),
125663dd9d8SGreg Roach                        ])
126663dd9d8SGreg Roach                        ->groupBy(['pl_parent_id', 'pl_place'])
127663dd9d8SGreg Roach                        ->having(new Expression('COUNT(*)'), '>', '1')
128663dd9d8SGreg Roach                        ->first();
129663dd9d8SGreg Roach
130663dd9d8SGreg Roach                    if ($row === null) {
131663dd9d8SGreg Roach                        break;
132663dd9d8SGreg Roach                    }
133663dd9d8SGreg Roach
134663dd9d8SGreg Roach                    // ...move children to the first
135663dd9d8SGreg Roach                    DB::table('placelocation')
136663dd9d8SGreg Roach                        ->where('pl_parent_id', '=', $row->max)
137663dd9d8SGreg Roach                        ->update(['pl_parent_id' => $row->min]);
138663dd9d8SGreg Roach
139663dd9d8SGreg Roach                    // ...delete the second
140663dd9d8SGreg Roach                    DB::table('placelocation')
141663dd9d8SGreg Roach                        ->where('pl_id', '=', $row->max)
142663dd9d8SGreg Roach                        ->delete();
143663dd9d8SGreg Roach                }
144663dd9d8SGreg Roach
145b344f1f7SGreg Roach                // This is the SQL standard.  It works with MySQL 8.0 and higher
1468155639aSGreg Roach                $select1 = DB::table('placelocation')
14790949315SGreg Roach                    ->leftJoin('place_location', 'id', '=', 'pl_id')
14890949315SGreg Roach                    ->whereNull('id')
14960e0106fSGreg Roach                    ->orderBy('pl_level')
15090949315SGreg Roach                    ->orderBy('pl_id')
15190949315SGreg Roach                    ->select([
15290949315SGreg Roach                        'pl_id',
15390949315SGreg Roach                        new Expression('CASE pl_parent_id WHEN 0 THEN NULL ELSE pl_parent_id END'),
15490949315SGreg Roach                        'pl_place',
155cec4277eSGreg Roach                        new Expression("CAST(REPLACE(REPLACE(pl_lati, 'S', '-'), 'N', '') AS FLOAT)"),
156cec4277eSGreg Roach                        new Expression("CAST(REPLACE(REPLACE(pl_long, 'W', '-'), 'E', '') AS FLOAT)"),
15790949315SGreg Roach                    ]);
1589a9dfcf7SGreg Roach
1598155639aSGreg Roach                // This works for MySQL 5.7 and lower, which cannot cast to FLOAT
1608155639aSGreg Roach                $select2 = DB::table('placelocation')
1618155639aSGreg Roach                    ->leftJoin('place_location', 'id', '=', 'pl_id')
1628155639aSGreg Roach                    ->whereNull('id')
16360e0106fSGreg Roach                    ->orderBy('pl_level')
1648155639aSGreg Roach                    ->orderBy('pl_id')
1658155639aSGreg Roach                    ->select([
1668155639aSGreg Roach                        'pl_id',
1678155639aSGreg Roach                        new Expression('CASE pl_parent_id WHEN 0 THEN NULL ELSE pl_parent_id END'),
1688155639aSGreg Roach                        'pl_place',
1698155639aSGreg Roach                        new Expression("REPLACE(REPLACE(pl_lati, 'S', '-'), 'N', '')"),
1708155639aSGreg Roach                        new Expression("REPLACE(REPLACE(pl_long, 'W', '-'), 'E', '')"),
1718155639aSGreg Roach                    ]);
1728155639aSGreg Roach
1738155639aSGreg Roach                try {
17490949315SGreg Roach                    DB::table('place_location')
1758155639aSGreg Roach                        ->insertUsing(['id', 'parent_id', 'place', 'latitude', 'longitude'], $select1);
17628d026adSGreg Roach                } catch (PDOException) {
1778155639aSGreg Roach                    DB::table('place_location')
1788155639aSGreg Roach                        ->insertUsing(['id', 'parent_id', 'place', 'latitude', 'longitude'], $select2);
1798155639aSGreg Roach                }
180b344f1f7SGreg Roach            }
1819a9dfcf7SGreg Roach
18290949315SGreg Roach            DB::schema()->drop('placelocation');
18390949315SGreg Roach        }
18490949315SGreg Roach
18590949315SGreg Roach        // Earlier versions of webtrees used 0 and NULL interchangeably.
18690949315SGreg Roach        // Assume 0 at the country-level and NULL at lower levels.
18790949315SGreg Roach        DB::table('place_location')
18890949315SGreg Roach            ->whereNotNull('parent_id')
18990949315SGreg Roach            ->where('latitude', '=', 0)
19090949315SGreg Roach            ->where('longitude', '=', 0)
19190949315SGreg Roach            ->update([
19290949315SGreg Roach                'latitude'  => null,
19390949315SGreg Roach                'longitude' => null,
19490949315SGreg Roach            ]);
1959a9dfcf7SGreg Roach    }
1969a9dfcf7SGreg Roach}
197