xref: /webtrees/app/Schema/Migration44.php (revision 3d2c98d1066d5e178a3d1ceb3bdc58b7ba8ee926)
1<?php
2
3/**
4 * webtrees: online genealogy
5 * Copyright (C) 2021 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 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            // The lack of unique key constraints means that there may be duplicates...
83            while (true) {
84                // Two places with the same name and parent...
85                $row = DB::table('placelocation')
86                    ->select([
87                        new Expression('MIN(pl_id) AS min'),
88                        new Expression('MAX(pl_id) AS max'),
89                    ])
90                    ->groupBy(['pl_parent_id', 'pl_place'])
91                    ->having(new Expression('COUNT(*)'), '>', '1')
92                    ->first();
93
94                if ($row === null) {
95                    break;
96                }
97
98                // ...move children to the first
99                DB::table('placelocation')
100                    ->where('pl_parent_id', '=', $row->max)
101                    ->update(['pl_parent_id' => $row->min]);
102
103                // ...delete the second
104                DB::table('placelocation')
105                    ->where('pl_id', '=', $row->max)
106                    ->delete();
107            }
108
109            // This is the SQL standard.  It works with Postgres, Sqlite and MySQL 8
110            $select1 = DB::table('placelocation')
111                ->leftJoin('place_location', 'id', '=', 'pl_id')
112                ->whereNull('id')
113                ->orderBy('pl_id')
114                ->select([
115                    'pl_id',
116                    new Expression('CASE pl_parent_id WHEN 0 THEN NULL ELSE pl_parent_id END'),
117                    'pl_place',
118                    new Expression("CAST(REPLACE(REPLACE(pl_lati, 'S', '-'), 'N', '') AS FLOAT)"),
119                    new Expression("CAST(REPLACE(REPLACE(pl_long, 'W', '-'), 'E', '') AS FLOAT)"),
120                ]);
121
122            // This works for MySQL 5.7 and lower, which cannot cast to FLOAT
123            $select2 = DB::table('placelocation')
124                ->leftJoin('place_location', 'id', '=', 'pl_id')
125                ->whereNull('id')
126                ->orderBy('pl_id')
127                ->select([
128                    'pl_id',
129                    new Expression('CASE pl_parent_id WHEN 0 THEN NULL ELSE pl_parent_id END'),
130                    'pl_place',
131                    new Expression("REPLACE(REPLACE(pl_lati, 'S', '-'), 'N', '')"),
132                    new Expression("REPLACE(REPLACE(pl_long, 'W', '-'), 'E', '')"),
133                ]);
134
135            try {
136                DB::table('place_location')
137                    ->insertUsing(['id', 'parent_id', 'place', 'latitude', 'longitude'], $select1);
138            } catch (PDOException $ex) {
139                DB::table('place_location')
140                    ->insertUsing(['id', 'parent_id', 'place', 'latitude', 'longitude'], $select2);
141            }
142
143            DB::schema()->drop('placelocation');
144        }
145
146        // Earlier versions of webtrees used 0 and NULL interchangeably.
147        // Assume 0 at the country-level and NULL at lower levels.
148        DB::table('place_location')
149            ->whereNotNull('parent_id')
150            ->where('latitude', '=', 0)
151            ->where('longitude', '=', 0)
152            ->update([
153                'latitude'  => null,
154                'longitude' => null,
155            ]);
156    }
157}
158