xref: /webtrees/app/Schema/Migration44.php (revision 81b514b4672980e5db010e9d89b55eaf131e798f)
1<?php
2
3/**
4 * webtrees: online genealogy
5 * Copyright (C) 2023 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\Expression;
24use Illuminate\Database\Schema\Blueprint;
25use PDOException;
26
27/**
28 * Upgrade the database schema from version 44 to version 45.
29 */
30class Migration44 implements MigrationInterface
31{
32    /**
33     * Upgrade to the next version
34     *
35     * @return void
36     */
37    public function upgrade(): void
38    {
39        // It is simpler to create a new table than to update the existing one.
40
41        if (!DB::schema()->hasTable('place_location')) {
42            DB::schema()->create('place_location', static function (Blueprint $table): void {
43                $table->integer('id', true);
44                $table->integer('parent_id')->nullable();
45                $table->string('place', 120);
46                $table->double('latitude')->nullable();
47                $table->double('longitude')->nullable();
48
49                $table->unique(['parent_id', 'place']);
50                $table->unique(['place', 'parent_id']);
51
52                $table->index(['latitude']);
53                $table->index(['longitude']);
54            });
55
56            // SQL-server cannot cascade-delete/update on self-relations.
57            // Users will need to delete all child locations before deleting the parent.
58            if (DB::connection()->getDriverName() === 'sqlsrv') {
59                // SQL-Server doesn't support 'RESTRICT'
60                $action = 'NO ACTION';
61            } else {
62                $action = 'CASCADE';
63            }
64
65            DB::schema()->table('place_location', static function (Blueprint $table) use ($action): void {
66                $table->foreign(['parent_id'])
67                    ->references(['id'])
68                    ->on('place_location')
69                    ->onDelete($action)
70                    ->onUpdate($action);
71            });
72        }
73
74        // This table should only exist if we are upgrading an old installation, which would have been
75        // created with MySQL.  Therefore we can safely use MySQL-specific SQL.
76        if (DB::schema()->hasTable('placelocation')) {
77            if (DB::connection()->getDriverName() === 'mysql') {
78                DB::table('placelocation')
79                    ->where('pl_lati', '=', '')
80                    ->orWhere('pl_long', '=', '')
81                    ->update([
82                        'pl_lati' => null,
83                        'pl_long' => null,
84                    ]);
85
86                // Missing/invalid parents?  Move them to the top level
87                DB::table('placelocation AS pl1')
88                    ->leftJoin('placelocation AS pl2', 'pl1.pl_parent_id', '=', 'pl2.pl_id')
89                    ->whereNull('pl2.pl_id')
90                    ->update([
91                        'pl1.pl_parent_id' => 0,
92                    ]);
93
94                // Remove invalid values.
95                DB::table('placelocation')
96                    ->where('pl_lati', 'NOT REGEXP', '^[NS][0-9]+[.]?[0-9]*$')
97                    ->orWhere('pl_long', 'NOT REGEXP', '^[EW][0-9]+[.]?[0-9]*$')
98                    ->update([
99                        'pl_lati' => null,
100                        'pl_long' => null,
101                    ]);
102
103                // The existing data may have placenames that only differ after the first 120 chars.
104                // Need to remove the constraint before we truncate/merge them.
105                try {
106                    DB::schema()->table('placelocation', static function (Blueprint $table): void {
107                        $table->dropUnique(['pl_parent_id', 'pl_place']);
108                    });
109                } catch (PDOException) {
110                    // Already deleted, or does not exist;
111                }
112
113                DB::table('placelocation')
114                    ->update([
115                        'pl_place' => new Expression('SUBSTRING(pl_place, 1, 120)'),
116                    ]);
117
118                // The lack of unique key constraints means that there may be duplicates...
119                while (true) {
120                    // Two places with the same name and parent...
121                    $row = DB::table('placelocation')
122                        ->select([
123                            new Expression('MIN(pl_id) AS min'),
124                            new Expression('MAX(pl_id) AS max'),
125                        ])
126                        ->groupBy(['pl_parent_id', 'pl_place'])
127                        ->having(new Expression('COUNT(*)'), '>', '1')
128                        ->first();
129
130                    if ($row === null) {
131                        break;
132                    }
133
134                    // ...move children to the first
135                    DB::table('placelocation')
136                        ->where('pl_parent_id', '=', $row->max)
137                        ->update(['pl_parent_id' => $row->min]);
138
139                    // ...delete the second
140                    DB::table('placelocation')
141                        ->where('pl_id', '=', $row->max)
142                        ->delete();
143                }
144
145                // This is the SQL standard.  It works with MySQL 8.0 and higher
146                $select1 = DB::table('placelocation')
147                    ->leftJoin('place_location', 'id', '=', 'pl_id')
148                    ->whereNull('id')
149                    ->orderBy('pl_level')
150                    ->orderBy('pl_id')
151                    ->select([
152                        'pl_id',
153                        new Expression('CASE pl_parent_id WHEN 0 THEN NULL ELSE pl_parent_id END'),
154                        'pl_place',
155                        new Expression("CAST(REPLACE(REPLACE(pl_lati, 'S', '-'), 'N', '') AS FLOAT)"),
156                        new Expression("CAST(REPLACE(REPLACE(pl_long, 'W', '-'), 'E', '') AS FLOAT)"),
157                    ]);
158
159                // This works for MySQL 5.7 and lower, which cannot cast to FLOAT
160                $select2 = DB::table('placelocation')
161                    ->leftJoin('place_location', 'id', '=', 'pl_id')
162                    ->whereNull('id')
163                    ->orderBy('pl_level')
164                    ->orderBy('pl_id')
165                    ->select([
166                        'pl_id',
167                        new Expression('CASE pl_parent_id WHEN 0 THEN NULL ELSE pl_parent_id END'),
168                        'pl_place',
169                        new Expression("REPLACE(REPLACE(pl_lati, 'S', '-'), 'N', '')"),
170                        new Expression("REPLACE(REPLACE(pl_long, 'W', '-'), 'E', '')"),
171                    ]);
172
173                try {
174                    DB::table('place_location')
175                        ->insertUsing(['id', 'parent_id', 'place', 'latitude', 'longitude'], $select1);
176                } catch (PDOException) {
177                    DB::table('place_location')
178                        ->insertUsing(['id', 'parent_id', 'place', 'latitude', 'longitude'], $select2);
179                }
180            }
181
182            DB::schema()->drop('placelocation');
183        }
184
185        // Earlier versions of webtrees used 0 and NULL interchangeably.
186        // Assume 0 at the country-level and NULL at lower levels.
187        DB::table('place_location')
188            ->whereNotNull('parent_id')
189            ->where('latitude', '=', 0)
190            ->where('longitude', '=', 0)
191            ->update([
192                'latitude'  => null,
193                'longitude' => null,
194            ]);
195    }
196}
197