xref: /webtrees/app/Schema/Migration44.php (revision 52550490b7095dd69811f3ec21ed5a3ca1a8968d)
19a9dfcf7SGreg Roach<?php
29a9dfcf7SGreg Roach
39a9dfcf7SGreg Roach/**
49a9dfcf7SGreg Roach * webtrees: online genealogy
5d11be702SGreg 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
226f4ec3caSGreg Roachuse Fisharebest\Webtrees\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    public function upgrade(): void
339a9dfcf7SGreg Roach    {
3490949315SGreg Roach        // It is simpler to create a new table than to update the existing one.
3590949315SGreg Roach
3690949315SGreg Roach        if (!DB::schema()->hasTable('place_location')) {
3790949315SGreg Roach            DB::schema()->create('place_location', static function (Blueprint $table): void {
3890949315SGreg Roach                $table->integer('id', true);
3990949315SGreg Roach                $table->integer('parent_id')->nullable();
4090949315SGreg Roach                $table->string('place', 120);
4190949315SGreg Roach                $table->double('latitude')->nullable();
4290949315SGreg Roach                $table->double('longitude')->nullable();
4390949315SGreg Roach
4490949315SGreg Roach                $table->unique(['parent_id', 'place']);
4590949315SGreg Roach                $table->unique(['place', 'parent_id']);
4690949315SGreg Roach
4790949315SGreg Roach                $table->index(['latitude']);
4890949315SGreg Roach                $table->index(['longitude']);
4990949315SGreg Roach            });
5090949315SGreg Roach
516ed487d2SGreg Roach            // SQL-server cannot cascade-delete/update on self-relations.
526ed487d2SGreg Roach            // Users will need to delete all child locations before deleting the parent.
53*52550490SGreg Roach            if (DB::driverName() === DB::SQL_SERVER) {
5468bce89dSGreg Roach                // SQL-Server doesn't support 'RESTRICT'
5568bce89dSGreg Roach                $action = 'NO ACTION';
566ed487d2SGreg Roach            } else {
576ed487d2SGreg Roach                $action = 'CASCADE';
586ed487d2SGreg Roach            }
596ed487d2SGreg Roach
606ed487d2SGreg Roach            DB::schema()->table('place_location', static function (Blueprint $table) use ($action): void {
6190949315SGreg Roach                $table->foreign(['parent_id'])
6290949315SGreg Roach                    ->references(['id'])
6390949315SGreg Roach                    ->on('place_location')
646ed487d2SGreg Roach                    ->onDelete($action)
656ed487d2SGreg Roach                    ->onUpdate($action);
669a9dfcf7SGreg Roach            });
679a9dfcf7SGreg Roach        }
689a9dfcf7SGreg Roach
69b344f1f7SGreg Roach        // This table should only exist if we are upgrading an old installation, which would have been
70b344f1f7SGreg Roach        // created with MySQL.  Therefore we can safely use MySQL-specific SQL.
7190949315SGreg Roach        if (DB::schema()->hasTable('placelocation')) {
72*52550490SGreg Roach            if (DB::driverName() === DB::MYSQL) {
739a9dfcf7SGreg Roach                DB::table('placelocation')
7490949315SGreg Roach                    ->where('pl_lati', '=', '')
7590949315SGreg Roach                    ->orWhere('pl_long', '=', '')
7690949315SGreg Roach                    ->update([
7790949315SGreg Roach                        'pl_lati' => null,
7890949315SGreg Roach                        'pl_long' => null,
7990949315SGreg Roach                    ]);
809a9dfcf7SGreg Roach
8129395507SGreg Roach                // Missing/invalid parents?  Move them to the top level
8229395507SGreg Roach                DB::table('placelocation AS pl1')
8329395507SGreg Roach                    ->leftJoin('placelocation AS pl2', 'pl1.pl_parent_id', '=', 'pl2.pl_id')
8429395507SGreg Roach                    ->whereNull('pl2.pl_id')
8529395507SGreg Roach                    ->update([
8629395507SGreg Roach                        'pl1.pl_parent_id' => 0,
8729395507SGreg Roach                    ]);
8829395507SGreg Roach
89b9c072a3SGreg Roach                // Remove invalid values.
90b9c072a3SGreg Roach                DB::table('placelocation')
91aa27872dSGreg Roach                    ->where('pl_lati', 'NOT REGEXP', '^[NS][0-9]+[.]?[0-9]*$')
92aa27872dSGreg Roach                    ->orWhere('pl_long', 'NOT REGEXP', '^[EW][0-9]+[.]?[0-9]*$')
93b9c072a3SGreg Roach                    ->update([
94aa27872dSGreg Roach                        'pl_lati' => null,
95aa27872dSGreg Roach                        'pl_long' => null,
96b9c072a3SGreg Roach                    ]);
97b9c072a3SGreg Roach
987a505637SGreg Roach                // The existing data may have placenames that only differ after the first 120 chars.
997a505637SGreg Roach                // Need to remove the constraint before we truncate/merge them.
1007a505637SGreg Roach                try {
1017a505637SGreg Roach                    DB::schema()->table('placelocation', static function (Blueprint $table): void {
10220338eabSGreg Roach                        $table->dropUnique(['pl_parent_id', 'pl_place']);
1037a505637SGreg Roach                    });
10428d026adSGreg Roach                } catch (PDOException) {
1057a505637SGreg Roach                    // Already deleted, or does not exist;
1067a505637SGreg Roach                }
1077a505637SGreg Roach
1087f27675cSGreg Roach                DB::table('placelocation')
1097f27675cSGreg Roach                    ->update([
110b344f1f7SGreg Roach                        'pl_place' => new Expression('SUBSTRING(pl_place, 1, 120)'),
1117f27675cSGreg Roach                    ]);
112b9c072a3SGreg Roach
113663dd9d8SGreg Roach                // The lack of unique key constraints means that there may be duplicates...
114663dd9d8SGreg Roach                while (true) {
115663dd9d8SGreg Roach                    // Two places with the same name and parent...
116663dd9d8SGreg Roach                    $row = DB::table('placelocation')
117663dd9d8SGreg Roach                        ->select([
118663dd9d8SGreg Roach                            new Expression('MIN(pl_id) AS min'),
119663dd9d8SGreg Roach                            new Expression('MAX(pl_id) AS max'),
120663dd9d8SGreg Roach                        ])
121663dd9d8SGreg Roach                        ->groupBy(['pl_parent_id', 'pl_place'])
122663dd9d8SGreg Roach                        ->having(new Expression('COUNT(*)'), '>', '1')
123663dd9d8SGreg Roach                        ->first();
124663dd9d8SGreg Roach
125663dd9d8SGreg Roach                    if ($row === null) {
126663dd9d8SGreg Roach                        break;
127663dd9d8SGreg Roach                    }
128663dd9d8SGreg Roach
129663dd9d8SGreg Roach                    // ...move children to the first
130663dd9d8SGreg Roach                    DB::table('placelocation')
131663dd9d8SGreg Roach                        ->where('pl_parent_id', '=', $row->max)
132663dd9d8SGreg Roach                        ->update(['pl_parent_id' => $row->min]);
133663dd9d8SGreg Roach
134663dd9d8SGreg Roach                    // ...delete the second
135663dd9d8SGreg Roach                    DB::table('placelocation')
136663dd9d8SGreg Roach                        ->where('pl_id', '=', $row->max)
137663dd9d8SGreg Roach                        ->delete();
138663dd9d8SGreg Roach                }
139663dd9d8SGreg Roach
140b344f1f7SGreg Roach                // This is the SQL standard.  It works with MySQL 8.0 and higher
1418155639aSGreg Roach                $select1 = DB::table('placelocation')
14290949315SGreg Roach                    ->leftJoin('place_location', 'id', '=', 'pl_id')
14390949315SGreg Roach                    ->whereNull('id')
14460e0106fSGreg Roach                    ->orderBy('pl_level')
14590949315SGreg Roach                    ->orderBy('pl_id')
14690949315SGreg Roach                    ->select([
14790949315SGreg Roach                        'pl_id',
14890949315SGreg Roach                        new Expression('CASE pl_parent_id WHEN 0 THEN NULL ELSE pl_parent_id END'),
14990949315SGreg Roach                        'pl_place',
150cec4277eSGreg Roach                        new Expression("CAST(REPLACE(REPLACE(pl_lati, 'S', '-'), 'N', '') AS FLOAT)"),
151cec4277eSGreg Roach                        new Expression("CAST(REPLACE(REPLACE(pl_long, 'W', '-'), 'E', '') AS FLOAT)"),
15290949315SGreg Roach                    ]);
1539a9dfcf7SGreg Roach
1548155639aSGreg Roach                // This works for MySQL 5.7 and lower, which cannot cast to FLOAT
1558155639aSGreg Roach                $select2 = DB::table('placelocation')
1568155639aSGreg Roach                    ->leftJoin('place_location', 'id', '=', 'pl_id')
1578155639aSGreg Roach                    ->whereNull('id')
15860e0106fSGreg Roach                    ->orderBy('pl_level')
1598155639aSGreg Roach                    ->orderBy('pl_id')
1608155639aSGreg Roach                    ->select([
1618155639aSGreg Roach                        'pl_id',
1628155639aSGreg Roach                        new Expression('CASE pl_parent_id WHEN 0 THEN NULL ELSE pl_parent_id END'),
1638155639aSGreg Roach                        'pl_place',
1648155639aSGreg Roach                        new Expression("REPLACE(REPLACE(pl_lati, 'S', '-'), 'N', '')"),
1658155639aSGreg Roach                        new Expression("REPLACE(REPLACE(pl_long, 'W', '-'), 'E', '')"),
1668155639aSGreg Roach                    ]);
1678155639aSGreg Roach
1688155639aSGreg Roach                try {
16990949315SGreg Roach                    DB::table('place_location')
1708155639aSGreg Roach                        ->insertUsing(['id', 'parent_id', 'place', 'latitude', 'longitude'], $select1);
17128d026adSGreg Roach                } catch (PDOException) {
1728155639aSGreg Roach                    DB::table('place_location')
1738155639aSGreg Roach                        ->insertUsing(['id', 'parent_id', 'place', 'latitude', 'longitude'], $select2);
1748155639aSGreg Roach                }
175b344f1f7SGreg Roach            }
1769a9dfcf7SGreg Roach
17790949315SGreg Roach            DB::schema()->drop('placelocation');
17890949315SGreg Roach        }
17990949315SGreg Roach
18090949315SGreg Roach        // Earlier versions of webtrees used 0 and NULL interchangeably.
18190949315SGreg Roach        // Assume 0 at the country-level and NULL at lower levels.
18290949315SGreg Roach        DB::table('place_location')
18390949315SGreg Roach            ->whereNotNull('parent_id')
18490949315SGreg Roach            ->where('latitude', '=', 0)
18590949315SGreg Roach            ->where('longitude', '=', 0)
18690949315SGreg Roach            ->update([
18790949315SGreg Roach                'latitude'  => null,
18890949315SGreg Roach                'longitude' => null,
18990949315SGreg Roach            ]);
1909a9dfcf7SGreg Roach    }
1919a9dfcf7SGreg Roach}
192