xref: /webtrees/app/Schema/Migration44.php (revision 10fc856aa190e25d705f56cb417fedd6439a0b0b)
1<?php
2
3/**
4 * webtrees: online genealogy
5 * Copyright (C) 2022 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            DB::schema()->table('place_location', static function (Blueprint $table): void {
57                $table->foreign(['parent_id'])
58                    ->references(['id'])
59                    ->on('place_location')
60                    ->onDelete('CASCADE')
61                    ->onUpdate('CASCADE');
62            });
63        }
64
65        if (DB::schema()->hasTable('placelocation')) {
66            DB::table('placelocation')
67                ->where('pl_lati', '=', '')
68                ->orWhere('pl_long', '=', '')
69                ->update([
70                    'pl_lati' => null,
71                    'pl_long' => null,
72                ]);
73
74            // Missing/invalid parents?  Move them to the top level
75            DB::table('placelocation AS pl1')
76                ->leftJoin('placelocation AS pl2', 'pl1.pl_parent_id', '=', 'pl2.pl_id')
77                ->whereNull('pl2.pl_id')
78                ->update([
79                    'pl1.pl_parent_id' => 0,
80                ]);
81
82            // Remove invalid values.
83            if (DB::connection()->getDriverName() === 'mysql') {
84                DB::table('placelocation')
85                    ->where('pl_lati', 'NOT REGEXP', '^[NS][0-9]+[.]?[0-9]*$')
86                    ->orWhere('pl_long', 'NOT REGEXP', '^[EW][0-9]+[.]?[0-9]*$')
87                    ->update([
88                        'pl_lati' => null,
89                        'pl_long' => null,
90                    ]);
91            }
92
93            // The existing data may have placenames that only differ after the first 120 chars.
94            // Need to remove the constraint before we truncate/merge them.
95            try {
96                DB::schema()->table('placelocation', static function (Blueprint $table): void {
97                    $table->dropUnique(['pl_parent_id', 'pl_place']);
98                });
99            } catch (PDOException $ex) {
100                // Already deleted, or does not exist;
101            }
102
103            $substring_function = DB::connection()->getDriverName() === 'sqlite' ? 'SUBSTR' : 'SUBSTRING';
104
105            DB::table('placelocation')
106                ->update([
107                    'pl_place' => new Expression($substring_function . '(pl_place, 1, 120)'),
108                ]);
109
110            // The lack of unique key constraints means that there may be duplicates...
111            while (true) {
112                // Two places with the same name and parent...
113                $row = DB::table('placelocation')
114                    ->select([
115                        new Expression('MIN(pl_id) AS min'),
116                        new Expression('MAX(pl_id) AS max'),
117                    ])
118                    ->groupBy(['pl_parent_id', 'pl_place'])
119                    ->having(new Expression('COUNT(*)'), '>', '1')
120                    ->first();
121
122                if ($row === null) {
123                    break;
124                }
125
126                // ...move children to the first
127                DB::table('placelocation')
128                    ->where('pl_parent_id', '=', $row->max)
129                    ->update(['pl_parent_id' => $row->min]);
130
131                // ...delete the second
132                DB::table('placelocation')
133                    ->where('pl_id', '=', $row->max)
134                    ->delete();
135            }
136
137            // This is the SQL standard.  It works with Postgres, Sqlite and MySQL 8
138            $select1 = DB::table('placelocation')
139                ->leftJoin('place_location', 'id', '=', 'pl_id')
140                ->whereNull('id')
141                ->orderBy('pl_level')
142                ->orderBy('pl_id')
143                ->select([
144                    'pl_id',
145                    new Expression('CASE pl_parent_id WHEN 0 THEN NULL ELSE pl_parent_id END'),
146                    'pl_place',
147                    new Expression("CAST(REPLACE(REPLACE(pl_lati, 'S', '-'), 'N', '') AS FLOAT)"),
148                    new Expression("CAST(REPLACE(REPLACE(pl_long, 'W', '-'), 'E', '') AS FLOAT)"),
149                ]);
150
151            // This works for MySQL 5.7 and lower, which cannot cast to FLOAT
152            $select2 = DB::table('placelocation')
153                ->leftJoin('place_location', 'id', '=', 'pl_id')
154                ->whereNull('id')
155                ->orderBy('pl_level')
156                ->orderBy('pl_id')
157                ->select([
158                    'pl_id',
159                    new Expression('CASE pl_parent_id WHEN 0 THEN NULL ELSE pl_parent_id END'),
160                    'pl_place',
161                    new Expression("REPLACE(REPLACE(pl_lati, 'S', '-'), 'N', '')"),
162                    new Expression("REPLACE(REPLACE(pl_long, 'W', '-'), 'E', '')"),
163                ]);
164
165            try {
166                DB::table('place_location')
167                    ->insertUsing(['id', 'parent_id', 'place', 'latitude', 'longitude'], $select1);
168            } catch (PDOException $ex) {
169                DB::table('place_location')
170                    ->insertUsing(['id', 'parent_id', 'place', 'latitude', 'longitude'], $select2);
171            }
172
173            DB::schema()->drop('placelocation');
174        }
175
176        // Earlier versions of webtrees used 0 and NULL interchangeably.
177        // Assume 0 at the country-level and NULL at lower levels.
178        DB::table('place_location')
179            ->whereNotNull('parent_id')
180            ->where('latitude', '=', 0)
181            ->where('longitude', '=', 0)
182            ->update([
183                'latitude'  => null,
184                'longitude' => null,
185            ]);
186    }
187}
188