1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
710
711
712
713
714
715
716
717
718
719
720
721
722
723
724
725
726
727
728
729
730
731
732
733
734
735
736
737
738
739
740
741
742
743
744
745
746
747
748
749
750
751
752
753
754
755
756
757
758
759
760
761
762
763
764
765
766
767
768
769
770
771
772
773
774
775
776
777
778
779
780
781
782
783
784
785
786
787
788
789
790
791
792
793
794
795
796
797
798
799
800
801
802
803
804
805
806
807
808
809
810
811
812
813
814
815
816
817
818
819
820
821
822
823
824
825
826
827
828
829
830
831
832
833
834
835
836
837
838
839
840
841
842
843
844
845
846
847
848
849
850
851
852
853
854
855
856
857
858
859
860
861
862
863
864
865
866
867
868
869
870
871
872
873
874
875
876
877
878
879
880
881
882
883
884
885
886
887
888
889
890
891
892
893
894
895
896
897
898
899
900
901
902
903
904
905
906
907
908
909
910
911
912
913
914
915
916
917
918
919
920
921
922
923
924
925
926
927
928
929
930
931
932
933
934
935
936
937
938
939
940
941
942
943
944
945
946
947
948
949
950
951
952
953
954
955
956
957
958
959
960
961
962
963
964
965
966
967
968
969
970
971
972
973
974
975
976
977
978
979
980
981
982
983
984
985
986
987
988
989
990
991
992
993
994
995
996
997
998
999
1000
1001
1002
1003
1004
1005
1006
1007
1008
1009
1010
1011
1012
1013
1014
1015
1016
1017
1018
1019
1020
1021
1022
1023
1024
1025
1026
1027
1028
1029
1030
1031
1032
1033
1034
1035
1036
1037
1038
1039
1040
1041
1042
1043
1044
1045
1046
1047
1048
1049
1050
1051
1052
1053
1054
1055
1056
1057
1058
1059
1060
1061
1062
1063
1064
1065
1066
1067
1068
1069
1070
1071
1072
1073
1074
1075
1076
1077
1078
1079
1080
1081
1082
1083
1084
1085
1086
1087
1088
1089
1090
1091
1092
1093
1094
1095
1096
1097
1098
1099
1100
1101
1102
1103
1104
1105
1106
1107
1108
1109
1110
1111
1112
1113
1114
1115
1116
1117
1118
1119
1120
1121
1122
1123
1124
1125
1126
1127
1128
1129
1130
1131
1132
1133
1134
1135
1136
1137
1138
1139
1140
1141
1142
1143
1144
1145
1146
1147
1148
1149
1150
1151
1152
1153
1154
1155
1156
1157
1158
1159
1160
1161
1162
1163
1164
1165
1166
1167
1168
1169
1170
1171
1172
1173
1174
1175
1176
1177
1178
1179
1180
1181
1182
1183
1184
1185
1186
1187
1188
1189
1190
1191
1192
1193
1194
1195
1196
1197
1198
1199
1200
1201
1202
1203
1204
1205
1206
1207
1208
1209
1210
1211
1212
1213
1214
1215
1216
1217
1218
1219
1220
1221
1222
1223
1224
1225
1226
1227
1228
1229
1230
1231
1232
1233
1234
1235
1236
1237
1238
1239
1240
1241
1242
1243
1244
1245
1246
1247
1248
1249
1250
1251
1252
1253
1254
1255
1256
1257
1258
1259
1260
1261
1262
1263
1264
1265
1266
1267
1268
1269
1270
1271
1272
1273
1274
1275
1276
1277
1278
1279
1280
1281
1282
1283
1284
1285
1286
1287
1288
1289
1290
1291
1292
1293
1294
1295
1296
1297
1298
1299
1300
1301
1302
1303
1304
1305
1306
1307
1308
1309
1310
1311
1312
1313
1314
1315
1316
1317
1318
1319
1320
1321
1322
1323
1324
1325
1326
1327
1328
1329
1330
1331
1332
1333
1334
1335
1336
1337
1338
1339
1340
1341
1342
1343
1344
1345
1346
1347
1348
1349
1350
1351
1352
1353
1354
1355
1356
1357
1358
1359
1360
1361
1362
1363
1364
1365
1366
1367
1368
1369
1370
1371
1372
1373
1374
1375
1376
1377
1378
1379
1380
1381
1382
1383
1384
1385
1386
1387
1388
1389
1390
1391
1392
1393
1394
1395
1396
1397
1398
1399
1400
1401
1402
1403
1404
1405
1406
1407
1408
1409
1410
1411
1412
1413
1414
1415
1416
1417
1418
1419
1420
1421
1422
1423
1424
1425
1426
1427
1428
1429
1430
1431
1432
1433
1434
1435
1436
1437
1438
1439
1440
1441
1442
1443
1444
1445
1446
1447
1448
1449
1450
1451
1452
1453
1454
1455
1456
1457
1458
1459
1460
1461
1462
1463
1464
1465
1466
1467
1468
1469
1470
1471
1472
1473
1474
1475
1476
1477
1478
1479
1480
1481
1482
1483
1484
1485
1486
1487
1488
1489
1490
1491
1492
1493
1494
1495
1496
1497
1498
1499
1500
1501
1502
1503
1504
1505
1506
1507
1508
1509
1510
1511
1512
1513
1514
1515
1516
1517
1518
1519
1520
1521
1522
1523
1524
1525
1526
1527
1528
1529
1530
1531
1532
1533
1534
1535
1536
1537
1538
1539
1540
1541
1542
1543
1544
1545
1546
1547
1548
1549
1550
1551
1552
1553
1554
1555
1556
1557
1558
1559
1560
1561
1562
1563
1564
1565
1566
1567
1568
1569
1570
1571
1572
1573
1574
1575
1576
1577
1578
1579
1580
1581
1582
1583
1584
1585
1586
1587
1588
1589
1590
1591
1592
1593
1594
1595
1596
1597
1598
1599
1600
1601
1602
1603
1604
1605
1606
1607
1608
1609
1610
1611
1612
1613
1614
1615
1616
1617
1618
1619
1620
1621
1622
1623
1624
1625
1626
1627
1628
1629
1630
1631
1632
1633
1634
1635
1636
1637
1638
1639
1640
1641
1642
1643
1644
1645
1646
1647
1648
1649
1650
1651
1652
1653
1654
1655
1656
1657
1658
1659
1660
1661
1662
1663
1664
1665
1666
1667
1668
1669
1670
1671
1672
1673
1674
1675
1676
1677
1678
1679
1680
1681
1682
1683
1684
1685
1686
1687
1688
1689
1690
1691
1692
1693
1694
1695
1696
1697
1698
1699
1700
1701
1702
1703
1704
1705
1706
1707
1708
1709
1710
1711
1712
1713
1714
1715
1716
1717
1718
1719
1720
1721
1722
1723
1724
1725
1726
1727
1728
1729
1730
1731
1732
1733
1734
1735
1736
1737
1738
1739
1740
1741
1742
1743
1744
1745
1746
1747
1748
1749
1750
1751
1752
1753
1754
1755
1756
1757
1758
1759
1760
1761
1762
1763
1764
1765
1766
1767
1768
1769
1770
1771
1772
1773
1774
1775
1776
1777
1778
1779
1780
1781
1782
1783
1784
1785
1786
1787
1788
1789
1790
1791
1792
1793
1794
1795
1796
1797
1798
1799
1800
1801
1802
1803
1804
1805
1806
1807
1808
1809
1810
1811
1812
1813
1814
1815
1816
1817
1818
1819
1820
1821
1822
1823
1824
1825
1826
1827
1828
1829
1830
1831
1832
1833
1834
1835
1836
1837
1838
1839
1840
1841
1842
1843
1844
1845
1846
1847
1848
1849
1850
1851
1852
1853
1854
1855
1856
1857
1858
1859
1860
1861
1862
1863
1864
1865
1866
1867
1868
1869
1870
1871
1872
1873
1874
1875
1876
1877
1878
1879
1880
1881
1882
1883
1884
1885
|
package Travelynx::Command::database;
# Copyright (C) 2020-2023 Daniel Friesel
#
# SPDX-License-Identifier: AGPL-3.0-or-later
use Mojo::Base 'Mojolicious::Command';
use DateTime;
use File::Slurp qw(read_file);
use JSON;
use Travel::Status::DE::IRIS::Stations;
has description => 'Initialize or upgrade database layout';
has usage => sub { shift->extract_usage };
sub get_schema_version {
my ( $db, $key ) = @_;
my $version;
$key //= 'version';
eval { $version = $db->select( 'schema_version', [$key] )->hash->{$key}; };
if ($@) {
# If it failed, the version table does not exist -> run setup first.
return undef;
}
return $version;
}
sub initialize_db {
my ($db) = @_;
$db->query(
qq{
create table schema_version (
version integer primary key
);
create table users (
id serial not null primary key,
name varchar(64) not null unique,
status smallint not null,
public_level smallint not null,
email varchar(256),
token varchar(80),
password text,
registered_at timestamptz not null,
last_login timestamptz not null,
deletion_requested timestamptz
);
create table stations (
id serial not null primary key,
ds100 varchar(16) not null unique,
name varchar(64) not null unique
);
create table user_actions (
id serial not null primary key,
user_id integer not null references users (id),
action_id smallint not null,
station_id int references stations (id),
action_time timestamptz not null,
train_type varchar(16),
train_line varchar(16),
train_no varchar(16),
train_id varchar(128),
sched_time timestamptz,
real_time timestamptz,
route text,
messages text
);
create table pending_mails (
email varchar(256) not null primary key,
num_tries smallint not null,
last_try timestamptz not null
);
create table tokens (
user_id integer not null references users (id),
type smallint not null,
token varchar(80) not null,
primary key (user_id, type)
);
insert into schema_version values (0);
}
);
}
my @migrations = (
# v0 -> v1
sub {
my ($db) = @_;
$db->query(
qq{
alter table user_actions
add column edited smallint;
drop table if exists monthly_stats;
create table journey_stats (
user_id integer not null references users (id),
year smallint not null,
month smallint not null,
data jsonb not null,
primary key (user_id, year, month)
);
update schema_version set version = 1;
}
);
},
# v1 -> v2
sub {
my ($db) = @_;
$db->query(
qq{
update user_actions set edited = 0;
alter table user_actions
alter column edited set not null;
update schema_version set version = 2;
}
);
},
# v2 -> v3
# A bug in the journey distance calculation caused excessive distances to be
# reported for routes covering stations without GPS coordinates. Ensure
# all caches are rebuilt.
sub {
my ($db) = @_;
$db->query(
qq{
truncate journey_stats;
update schema_version set version = 3;
}
);
},
# v3 -> v4
# Introduces "journeys", containing one row for each complete
# journey, and "in_transit", containing the journey which is currently
# in progress (if any). "user_actions" is no longer used, but still kept
# as a backup for now.
sub {
my ($db) = @_;
$db->query(
qq{
create table journeys (
id serial not null primary key,
user_id integer not null references users (id),
train_type varchar(16) not null,
train_line varchar(16),
train_no varchar(16) not null,
train_id varchar(128) not null,
checkin_station_id integer not null references stations (id),
checkin_time timestamptz not null,
sched_departure timestamptz not null,
real_departure timestamptz not null,
checkout_station_id integer not null references stations (id),
checkout_time timestamptz not null,
sched_arrival timestamptz,
real_arrival timestamptz,
cancelled boolean not null,
edited smallint not null,
route text,
messages text
);
create table in_transit (
user_id integer not null references users (id) primary key,
train_type varchar(16) not null,
train_line varchar(16),
train_no varchar(16) not null,
train_id varchar(128) not null,
checkin_station_id integer not null references stations (id),
checkin_time timestamptz not null,
sched_departure timestamptz not null,
real_departure timestamptz not null,
checkout_station_id int references stations (id),
checkout_time timestamptz,
sched_arrival timestamptz,
real_arrival timestamptz,
cancelled boolean not null,
route text,
messages text
);
create view journeys_str as select
journeys.id as journey_id, user_id,
train_type, train_line, train_no, train_id,
extract(epoch from checkin_time) as checkin_ts,
extract(epoch from sched_departure) as sched_dep_ts,
extract(epoch from real_departure) as real_dep_ts,
dep_stations.ds100 as dep_ds100,
dep_stations.name as dep_name,
extract(epoch from checkout_time) as checkout_ts,
extract(epoch from sched_arrival) as sched_arr_ts,
extract(epoch from real_arrival) as real_arr_ts,
arr_stations.ds100 as arr_ds100,
arr_stations.name as arr_name,
cancelled, edited, route, messages
from journeys
join stations as dep_stations on dep_stations.id = checkin_station_id
join stations as arr_stations on arr_stations.id = checkout_station_id
;
create view in_transit_str as select
user_id,
train_type, train_line, train_no, train_id,
extract(epoch from checkin_time) as checkin_ts,
extract(epoch from sched_departure) as sched_dep_ts,
extract(epoch from real_departure) as real_dep_ts,
dep_stations.ds100 as dep_ds100,
dep_stations.name as dep_name,
extract(epoch from checkout_time) as checkout_ts,
extract(epoch from sched_arrival) as sched_arr_ts,
extract(epoch from real_arrival) as real_arr_ts,
arr_stations.ds100 as arr_ds100,
arr_stations.name as arr_name,
cancelled, route, messages
from in_transit
join stations as dep_stations on dep_stations.id = checkin_station_id
left join stations as arr_stations on arr_stations.id = checkout_station_id
;
}
);
my @uids
= $db->select( 'users', ['id'] )->hashes->map( sub { shift->{id} } )
->each;
my $count = 0;
for my $uid (@uids) {
my %cache;
my $prev_action_type = 0;
my $actions = $db->select(
'user_actions', '*',
{ user_id => $uid },
{ order_by => { -asc => 'id' } }
);
for my $action ( $actions->hashes->each ) {
my $action_type = $action->{action_id};
my $id = $action->{id};
if ( $action_type == 2 and $prev_action_type != 1 ) {
die(
"Inconsistent data at uid ${uid} action ${id}: Illegal transition $prev_action_type -> $action_type.\n"
);
}
if ( $action_type == 5 and $prev_action_type != 4 ) {
die(
"Inconsistent data at uid ${uid} action ${id}: Illegal transition $prev_action_type -> $action_type.\n"
);
}
if ( $action_type == 1 or $action_type == 4 ) {
%cache = (
train_type => $action->{train_type},
train_line => $action->{train_line},
train_no => $action->{train_no},
train_id => $action->{train_id},
checkin_station_id => $action->{station_id},
checkin_time => $action->{action_time},
sched_departure => $action->{sched_time},
real_departure => $action->{real_time},
route => $action->{route},
messages => $action->{messages},
cancelled => $action->{action_id} == 4 ? 1 : 0,
edited => $action->{edited},
);
}
elsif ( $action_type == 2 or $action_type == 5 ) {
$cache{checkout_station_id} = $action->{station_id};
$cache{checkout_time} = $action->{action_time};
$cache{sched_arrival} = $action->{sched_time};
$cache{real_arrival} = $action->{real_time};
$cache{edited} |= $action->{edited} << 8;
if ( $action->{route} ) {
$cache{route} = $action->{route};
}
if ( $action->{messages} ) {
$cache{messages} = $action->{messages};
}
$db->insert(
'journeys',
{
user_id => $uid,
train_type => $cache{train_type},
train_line => $cache{train_line},
train_no => $cache{train_no},
train_id => $cache{train_id},
checkin_station_id => $cache{checkin_station_id},
checkin_time => $cache{checkin_time},
sched_departure => $cache{sched_departure},
real_departure => $cache{real_departure},
checkout_station_id => $cache{checkout_station_id},
checkout_time => $cache{checkout_time},
sched_arrival => $cache{sched_arrival},
real_arrival => $cache{real_arrival},
cancelled => $cache{cancelled},
edited => $cache{edited},
route => $cache{route},
messages => $cache{messages}
}
);
%cache = ();
}
$prev_action_type = $action_type;
}
if (%cache) {
# user is currently in transit
$db->insert(
'in_transit',
{
user_id => $uid,
train_type => $cache{train_type},
train_line => $cache{train_line},
train_no => $cache{train_no},
train_id => $cache{train_id},
checkin_station_id => $cache{checkin_station_id},
checkin_time => $cache{checkin_time},
sched_departure => $cache{sched_departure},
real_departure => $cache{real_departure},
cancelled => $cache{cancelled},
route => $cache{route},
messages => $cache{messages}
}
);
}
$count++;
printf( " journey storage migration: %3.0f%% complete\n",
$count * 100 / @uids );
}
$db->update( 'schema_version', { version => 4 } );
},
# v4 -> v5
# Handle inconsistent data (overlapping journeys) in statistics. Introduces
# the "inconsistencies" stats key -> rebuild all stats.
sub {
my ($db) = @_;
$db->query(
qq{
truncate journey_stats;
update schema_version set version = 5;
}
);
},
# v5 -> v6
# Add documentation
sub {
my ($db) = @_;
$db->query(
qq{
comment on table in_transit is 'Users who are currently checked into a train';
comment on view in_transit_str is 'in_transit with station IDs resolved to name/ds100';
comment on table journey_stats is 'Cache for yearly and monthly statistics in JSON format';
comment on table journeys is 'Past train trips (i.e. the user has already checked out)';
comment on view journeys_str is 'journeys with station IDs resolved to name/ds100';
comment on table pending_mails is 'Blacklist for mail addresses used in an unsuccessful registration attempt. Helps ensure that travelynx does not spam individual mails with registration attempts.';
comment on table stations is 'Map of station IDs to name and DS100 code';
comment on table tokens is 'User API tokens';
comment on column in_transit.route is 'Format: station1|station2|station3|...';
comment on column in_transit.messages is 'Format: epoch:message1|epoch:message2|...';
comment on column in_transit_str.route is 'Format: station1|station2|station3|...';
comment on column in_transit_str.messages is 'Format: epoch:message1|epoch:message2|...';
comment on column journeys.edited is 'Bit mask indicating which part has been entered manually. 0x0001 = sched departure, 0x0002 = real departure, 0x0100 = sched arrival, 0x0200 = real arrival';
comment on column journeys.route is 'Format: station1|station2|station3|...';
comment on column journeys.messages is 'Format: epoch:message1|epoch:message2|...';
comment on column journeys_str.edited is 'Bit mask indicating which part has been entered manually. 0x0001 = sched departure, 0x0002 = real departure, 0x0100 = sched arrival, 0x0200 = real arrival';
comment on column journeys_str.route is 'Format: station1|station2|station3|...';
comment on column journeys_str.messages is 'Format: epoch:message1|epoch:message2|...';
comment on column users.status is 'Bit mask: 0x01 = verified';
comment on column users.public_level is 'Bit mask indicating public account parts. 0x01 = current status (checkin from/to or last checkout at)';
comment on column users.token is 'Used for e-mail verification';
comment on column users.deletion_requested is 'Time at which account deletion was requested';
update schema_version set version = 6;
}
);
},
# v6 -> v7
# Add pending_passwords table to store data about pending password resets
sub {
my ($db) = @_;
$db->query(
qq{
create table pending_passwords (
user_id integer not null references users (id) primary key,
token varchar(80) not null,
requested_at timestamptz not null
);
comment on table pending_passwords is 'Password reset tokens';
update schema_version set version = 7;
}
);
},
# v7 -> v8
# Add pending_mails table to store data about pending mail changes
sub {
my ($db) = @_;
$db->query(
qq{
alter table pending_mails rename to mail_blacklist;
create table pending_mails (
user_id integer not null references users (id) primary key,
email varchar(256) not null,
token varchar(80) not null,
requested_at timestamptz not null
);
comment on table pending_mails is 'Verification tokens for mail address changes';
update schema_version set version = 8;
}
);
},
# v8 -> v9
sub {
my ($db) = @_;
$db->query(
qq{
alter table users rename column last_login to last_seen;
drop table user_actions;
update schema_version set version = 9;
}
);
},
# v9 -> v10
# Add pending_registrations table. The users.token column is no longer
# needed.
sub {
my ($db) = @_;
$db->query(
qq{
create table pending_registrations (
user_id integer not null references users (id) primary key,
token varchar(80) not null
);
comment on table pending_registrations is 'Verification tokens for newly registered accounts';
update schema_version set version = 10;
}
);
my $res = $db->select( 'users', [ 'id', 'token' ], { status => 0 } );
for my $user ( $res->hashes->each ) {
$db->insert(
'pending_registrations',
{
user_id => $user->{id},
token => $user->{token}
}
);
}
$db->query(
qq{
alter table users drop column token;
}
);
},
# v10 -> v11
sub {
my ($db) = @_;
$db->query(
qq{
create table webhooks (
user_id integer not null references users (id) primary key,
enabled boolean not null,
url varchar(1000) not null,
token varchar(250),
errored boolean,
latest_run timestamptz,
output text
);
comment on table webhooks is 'URLs and bearer tokens for push events';
create view webhooks_str as select
user_id, enabled, url, token, errored, output,
extract(epoch from latest_run) as latest_run_ts
from webhooks
;
update schema_version set version = 11;
}
);
},
# v11 -> v12
sub {
my ($db) = @_;
$db->query(
qq{
alter table journeys
add column dep_platform varchar(16),
add column arr_platform varchar(16);
alter table in_transit
add column dep_platform varchar(16),
add column arr_platform varchar(16);
create or replace view journeys_str as select
journeys.id as journey_id, user_id,
train_type, train_line, train_no, train_id,
extract(epoch from checkin_time) as checkin_ts,
extract(epoch from sched_departure) as sched_dep_ts,
extract(epoch from real_departure) as real_dep_ts,
dep_stations.ds100 as dep_ds100,
dep_stations.name as dep_name,
extract(epoch from checkout_time) as checkout_ts,
extract(epoch from sched_arrival) as sched_arr_ts,
extract(epoch from real_arrival) as real_arr_ts,
arr_stations.ds100 as arr_ds100,
arr_stations.name as arr_name,
cancelled, edited, route, messages,
dep_platform, arr_platform
from journeys
join stations as dep_stations on dep_stations.id = checkin_station_id
join stations as arr_stations on arr_stations.id = checkout_station_id
;
create or replace view in_transit_str as select
user_id,
train_type, train_line, train_no, train_id,
extract(epoch from checkin_time) as checkin_ts,
extract(epoch from sched_departure) as sched_dep_ts,
extract(epoch from real_departure) as real_dep_ts,
dep_stations.ds100 as dep_ds100,
dep_stations.name as dep_name,
extract(epoch from checkout_time) as checkout_ts,
extract(epoch from sched_arrival) as sched_arr_ts,
extract(epoch from real_arrival) as real_arr_ts,
arr_stations.ds100 as arr_ds100,
arr_stations.name as arr_name,
cancelled, route, messages,
dep_platform, arr_platform
from in_transit
join stations as dep_stations on dep_stations.id = checkin_station_id
left join stations as arr_stations on arr_stations.id = checkout_station_id
;
update schema_version set version = 12;
}
);
},
# v12 -> v13
sub {
my ($db) = @_;
$db->query(
qq{
alter table users add column use_history smallint default 255;
update schema_version set version = 13;
}
);
},
# v13 -> v14
sub {
my ($db) = @_;
$db->query(
qq{
alter table journeys add column route_new jsonb,
add column messages_new jsonb;
alter table in_transit add column route_new jsonb,
add column messages_new jsonb;
}
);
my $res = $db->select( 'journeys', [ 'id', 'messages', 'route' ] );
my $json = JSON->new;
for my $journey ( $res->hashes->each ) {
my $id = $journey->{id};
my @messages;
for my $message ( split( qr{[|]}, $journey->{messages} // '' ) ) {
my ( $ts, $msg ) = split( qr{:}, $message );
push( @messages, [ $ts, $msg ] );
}
my @route = map { [$_] }
split( qr{[|]}, $journey->{route} // '' );
$db->update(
'journeys',
{
messages_new => $json->encode( [@messages] ),
route_new => $json->encode( [@route] ),
},
{ id => $id }
);
}
$res = $db->select( 'in_transit', [ 'user_id', 'messages', 'route' ] );
for my $journey ( $res->hashes->each ) {
my $id = $journey->{user_id};
my @messages;
for my $message ( split( qr{[|]}, $journey->{messages} // '' ) ) {
my ( $ts, $msg ) = split( qr{:}, $message );
push( @messages, [ $ts, $msg ] );
}
my @route = map { [$_] }
split( qr{[|]}, $journey->{route} // '' );
$db->update(
'in_transit',
{
messages_new => $json->encode( [@messages] ),
route_new => $json->encode( [@route] ),
},
{ user_id => $id }
);
}
$db->query(
qq{
drop view journeys_str;
alter table journeys drop column messages;
alter table journeys drop column route;
alter table journeys rename column messages_new to messages;
alter table journeys rename column route_new to route;
drop view in_transit_str;
alter table in_transit drop column messages;
alter table in_transit drop column route;
alter table in_transit rename column messages_new to messages;
alter table in_transit rename column route_new to route;
create view journeys_str as select
journeys.id as journey_id, user_id,
train_type, train_line, train_no, train_id,
extract(epoch from checkin_time) as checkin_ts,
extract(epoch from sched_departure) as sched_dep_ts,
extract(epoch from real_departure) as real_dep_ts,
dep_stations.ds100 as dep_ds100,
dep_stations.name as dep_name,
extract(epoch from checkout_time) as checkout_ts,
extract(epoch from sched_arrival) as sched_arr_ts,
extract(epoch from real_arrival) as real_arr_ts,
arr_stations.ds100 as arr_ds100,
arr_stations.name as arr_name,
cancelled, edited, route, messages,
dep_platform, arr_platform
from journeys
join stations as dep_stations on dep_stations.id = checkin_station_id
join stations as arr_stations on arr_stations.id = checkout_station_id
;
create view in_transit_str as select
user_id,
train_type, train_line, train_no, train_id,
extract(epoch from checkin_time) as checkin_ts,
extract(epoch from sched_departure) as sched_dep_ts,
extract(epoch from real_departure) as real_dep_ts,
dep_stations.ds100 as dep_ds100,
dep_stations.name as dep_name,
extract(epoch from checkout_time) as checkout_ts,
extract(epoch from sched_arrival) as sched_arr_ts,
extract(epoch from real_arrival) as real_arr_ts,
arr_stations.ds100 as arr_ds100,
arr_stations.name as arr_name,
cancelled, route, messages,
dep_platform, arr_platform
from in_transit
join stations as dep_stations on dep_stations.id = checkin_station_id
left join stations as arr_stations on arr_stations.id = checkout_station_id
;
update schema_version set version = 14;
}
);
},
# v14 -> v15
sub {
my ($db) = @_;
$db->query(
qq{
alter table in_transit add column data jsonb;
create or replace view in_transit_str as select
user_id,
train_type, train_line, train_no, train_id,
extract(epoch from checkin_time) as checkin_ts,
extract(epoch from sched_departure) as sched_dep_ts,
extract(epoch from real_departure) as real_dep_ts,
dep_stations.ds100 as dep_ds100,
dep_stations.name as dep_name,
extract(epoch from checkout_time) as checkout_ts,
extract(epoch from sched_arrival) as sched_arr_ts,
extract(epoch from real_arrival) as real_arr_ts,
arr_stations.ds100 as arr_ds100,
arr_stations.name as arr_name,
cancelled, route, messages,
dep_platform, arr_platform, data
from in_transit
join stations as dep_stations on dep_stations.id = checkin_station_id
left join stations as arr_stations on arr_stations.id = checkout_station_id
;
update schema_version set version = 15;
}
);
},
# v15 -> v16
# Beeline distance calculation now also works when departure or arrival
# station do not have geo-coordinates (by resorting to the first/last
# station in the route which does have geo-coordinates). Previously,
# beeline distances were reported as zero in this case. Clear caches
# to recalculate total distances per year / month.
sub {
my ($db) = @_;
$db->query(
qq{
truncate journey_stats;
update schema_version set version = 16;
}
);
},
# v16 -> v17
sub {
my ($db) = @_;
$db->query(
qq{
drop view journeys_str;
drop view in_transit_str;
alter table journeys add column user_data jsonb;
alter table in_transit add column user_data jsonb;
create view journeys_str as select
journeys.id as journey_id, user_id,
train_type, train_line, train_no, train_id,
extract(epoch from checkin_time) as checkin_ts,
extract(epoch from sched_departure) as sched_dep_ts,
extract(epoch from real_departure) as real_dep_ts,
dep_stations.ds100 as dep_ds100,
dep_stations.name as dep_name,
extract(epoch from checkout_time) as checkout_ts,
extract(epoch from sched_arrival) as sched_arr_ts,
extract(epoch from real_arrival) as real_arr_ts,
arr_stations.ds100 as arr_ds100,
arr_stations.name as arr_name,
cancelled, edited, route, messages, user_data,
dep_platform, arr_platform
from journeys
join stations as dep_stations on dep_stations.id = checkin_station_id
join stations as arr_stations on arr_stations.id = checkout_station_id
;
create view in_transit_str as select
user_id,
train_type, train_line, train_no, train_id,
extract(epoch from checkin_time) as checkin_ts,
extract(epoch from sched_departure) as sched_dep_ts,
extract(epoch from real_departure) as real_dep_ts,
dep_stations.ds100 as dep_ds100,
dep_stations.name as dep_name,
extract(epoch from checkout_time) as checkout_ts,
extract(epoch from sched_arrival) as sched_arr_ts,
extract(epoch from real_arrival) as real_arr_ts,
arr_stations.ds100 as arr_ds100,
arr_stations.name as arr_name,
cancelled, route, messages, user_data,
dep_platform, arr_platform
from in_transit
join stations as dep_stations on dep_stations.id = checkin_station_id
left join stations as arr_stations on arr_stations.id = checkout_station_id
;
}
);
for my $journey ( $db->select( 'journeys', [ 'id', 'messages' ] )
->expand->hashes->each )
{
if ( $journey->{messages}
and @{ $journey->{messages} }
and $journey->{messages}[0][0] == 0 )
{
my $comment = $journey->{messages}[0][1];
$db->update(
'journeys',
{
user_data =>
JSON->new->encode( { comment => $comment } ),
messages => undef
},
{ id => $journey->{id} }
);
}
}
$db->query(
qq{
update schema_version set version = 17;
}
);
},
# v17 -> v18
sub {
my ($db) = @_;
$db->query(
qq{
create or replace view in_transit_str as select
user_id,
train_type, train_line, train_no, train_id,
extract(epoch from checkin_time) as checkin_ts,
extract(epoch from sched_departure) as sched_dep_ts,
extract(epoch from real_departure) as real_dep_ts,
dep_stations.ds100 as dep_ds100,
dep_stations.name as dep_name,
extract(epoch from checkout_time) as checkout_ts,
extract(epoch from sched_arrival) as sched_arr_ts,
extract(epoch from real_arrival) as real_arr_ts,
arr_stations.ds100 as arr_ds100,
arr_stations.name as arr_name,
cancelled, route, messages, user_data,
dep_platform, arr_platform, data
from in_transit
join stations as dep_stations on dep_stations.id = checkin_station_id
left join stations as arr_stations on arr_stations.id = checkout_station_id
;
update schema_version set version = 18;
}
);
},
# v18 -> v19
sub {
my ($db) = @_;
say
'Transitioning from travelynx station ID to EVA IDs, this may take a while ...';
$db->query(
qq{
alter table in_transit drop constraint in_transit_checkin_station_id_fkey;
alter table in_transit drop constraint in_transit_checkout_station_id_fkey;
alter table journeys drop constraint journeys_checkin_station_id_fkey;
alter table journeys drop constraint journeys_checkout_station_id_fkey;
}
);
for my $journey ( $db->select( 'in_transit_str', '*' )->hashes->each ) {
my ($s_dep)
= Travel::Status::DE::IRIS::Stations::get_station(
$journey->{dep_ds100} );
if ( $s_dep->[1] ne $journey->{dep_name} ) {
die(
"$s_dep->[0] name mismatch: $s_dep->[1] vs. $journey->{dep_name}"
);
}
my $rows = $db->update(
'in_transit',
{ checkin_station_id => $s_dep->[2] },
{ user_id => $journey->{user_id} }
)->rows;
if ( $rows != 1 ) {
die(
"Update error at in_transit checkin_station_id UID $journey->{user_id}\n"
);
}
if ( $journey->{arr_ds100} ) {
my ($s_arr)
= Travel::Status::DE::IRIS::Stations::get_station(
$journey->{arr_ds100} );
if ( $s_arr->[1] ne $journey->{arr_name} ) {
die(
"$s_arr->[0] name mismatch: $s_arr->[1] vs. $journey->{arr_name}"
);
}
my $rows = $db->update(
'in_transit',
{ checkout_station_id => $s_arr->[2] },
{ user_id => $journey->{user_id} }
)->rows;
if ( $rows != 1 ) {
die(
"Update error at in_transit checkout_station_id UID $journey->{user_id}\n"
);
}
}
}
for my $journey ( $db->select( 'journeys_str', '*' )->hashes->each ) {
my ($s_dep)
= Travel::Status::DE::IRIS::Stations::get_station(
$journey->{dep_ds100} );
my ($s_arr)
= Travel::Status::DE::IRIS::Stations::get_station(
$journey->{arr_ds100} );
if ( $s_dep->[1] ne $journey->{dep_name} ) {
die(
"$s_dep->[0] name mismatch: $s_dep->[1] vs. $journey->{dep_name}"
);
}
my $rows = $db->update(
'journeys',
{ checkin_station_id => $s_dep->[2] },
{ id => $journey->{journey_id} }
)->rows;
if ( $rows != 1 ) {
die(
"While updating journeys#checkin_station_id for journey $journey->{id}: got $rows rows, expected 1\n"
);
}
if ( $s_arr->[1] ne $journey->{arr_name} ) {
die(
"$s_arr->[0] name mismatch: $s_arr->[1] vs. $journey->{arr_name}"
);
}
$rows = $db->update(
'journeys',
{ checkout_station_id => $s_arr->[2] },
{ id => $journey->{journey_id} }
)->rows;
if ( $rows != 1 ) {
die(
"While updating journeys#checkout_station_id for journey $journey->{id}: got $rows rows, expected 1\n"
);
}
}
$db->query(
qq{
drop view journeys_str;
drop view in_transit_str;
create view journeys_str as select
journeys.id as journey_id, user_id,
train_type, train_line, train_no, train_id,
extract(epoch from checkin_time) as checkin_ts,
extract(epoch from sched_departure) as sched_dep_ts,
extract(epoch from real_departure) as real_dep_ts,
checkin_station_id as dep_eva,
extract(epoch from checkout_time) as checkout_ts,
extract(epoch from sched_arrival) as sched_arr_ts,
extract(epoch from real_arrival) as real_arr_ts,
checkout_station_id as arr_eva,
cancelled, edited, route, messages, user_data,
dep_platform, arr_platform
from journeys
;
create or replace view in_transit_str as select
user_id,
train_type, train_line, train_no, train_id,
extract(epoch from checkin_time) as checkin_ts,
extract(epoch from sched_departure) as sched_dep_ts,
extract(epoch from real_departure) as real_dep_ts,
checkin_station_id as dep_eva,
extract(epoch from checkout_time) as checkout_ts,
extract(epoch from sched_arrival) as sched_arr_ts,
extract(epoch from real_arrival) as real_arr_ts,
checkout_station_id as arr_eva,
cancelled, route, messages, user_data,
dep_platform, arr_platform, data
from in_transit
;
drop table stations;
update schema_version set version = 19;
}
);
},
# v19 -> v20
sub {
my ($db) = @_;
$db->query(
qq{
create table polylines (
id serial not null primary key,
origin_eva integer not null,
destination_eva integer not null,
polyline jsonb not null
);
alter table journeys
add column polyline_id integer references polylines (id);
alter table in_transit
add column polyline_id integer references polylines (id);
drop view journeys_str;
drop view in_transit_str;
create view journeys_str as select
journeys.id as journey_id, user_id,
train_type, train_line, train_no, train_id,
extract(epoch from checkin_time) as checkin_ts,
extract(epoch from sched_departure) as sched_dep_ts,
extract(epoch from real_departure) as real_dep_ts,
checkin_station_id as dep_eva,
extract(epoch from checkout_time) as checkout_ts,
extract(epoch from sched_arrival) as sched_arr_ts,
extract(epoch from real_arrival) as real_arr_ts,
checkout_station_id as arr_eva,
polylines.polyline as polyline,
cancelled, edited, route, messages, user_data,
dep_platform, arr_platform
from journeys
left join polylines on polylines.id = polyline_id
;
create or replace view in_transit_str as select
user_id,
train_type, train_line, train_no, train_id,
extract(epoch from checkin_time) as checkin_ts,
extract(epoch from sched_departure) as sched_dep_ts,
extract(epoch from real_departure) as real_dep_ts,
checkin_station_id as dep_eva,
extract(epoch from checkout_time) as checkout_ts,
extract(epoch from sched_arrival) as sched_arr_ts,
extract(epoch from real_arrival) as real_arr_ts,
checkout_station_id as arr_eva,
polylines.polyline as polyline,
cancelled, route, messages, user_data,
dep_platform, arr_platform, data
from in_transit
left join polylines on polylines.id = polyline_id
;
update schema_version set version = 20;
}
);
},
# v20 -> v21
# After introducing polyline support, journey distance calculation diverged:
# the detail view (individual train) used the polyline, whereas monthly and
# yearly statistics were still based on beeline between intermediate stops.
# Release 1.16.0 fixes this -> ensure all caches are rebuilt.
sub {
my ($db) = @_;
$db->query(
qq{
truncate journey_stats;
update schema_version set version = 21;
}
);
},
# v21 -> v22
sub {
my ($db) = @_;
$db->query(
qq{
create table traewelling (
user_id integer not null references users (id) primary key,
email varchar(256) not null,
push_sync boolean not null,
pull_sync boolean not null,
errored boolean,
token text,
data jsonb,
latest_run timestamptz
);
comment on table traewelling is 'Token and Status for Traewelling';
create view traewelling_str as select
user_id, email, push_sync, pull_sync, errored, token, data,
extract(epoch from latest_run) as latest_run_ts
from traewelling
;
update schema_version set version = 22;
}
);
},
# v22 -> v23
# 1.18.1 fixes handling of negative cumulative arrival/departure delays
# and introduces additional statistics entries with pre-formatted duration
# strings while at it. Old cache entries lack those.
sub {
my ($db) = @_;
$db->query(
qq{
truncate journey_stats;
update schema_version set version = 23;
}
);
},
# v23 -> v24
# travelynx 1.22 warns about upcoming account deletion due to inactivity
sub {
my ($db) = @_;
$db->query(
qq{
alter table users add column deletion_notified timestamptz;
comment on column users.deletion_notified is 'Time at which warning about upcoming account deletion due to inactivity was sent';
update schema_version set version = 24;
}
);
},
# v24 -> v25
# travelynx 1.23 adds optional links to external services, e.g.
# DBF or bahn.expert departure boards
sub {
my ($db) = @_;
$db->query(
qq{
alter table users add column external_services smallint;
comment on column users.external_services is 'Which external service to use for stationboard or routing links';
update schema_version set version = 25;
}
);
},
# v25 -> v26
# travelynx 1.24 adds local transit connections and needs to know targets
# for that to work, as local transit does not support checkins yet.
sub {
my ($db) = @_;
$db->query(
qq{
create table localtransit (
user_id integer not null references users (id) primary key,
data jsonb
);
create view user_transit as select
id,
use_history,
localtransit.data as data
from users
left join localtransit on localtransit.user_id = id
;
update schema_version set version = 26;
}
);
},
# v26 -> v27
# add list of stations that are not (or no longer) present in T-S-DE-IRIS
# (in this case, stations that were removed up to 1.74)
sub {
my ($db) = @_;
$db->query(
qq{
alter table schema_version
add column iris varchar(12);
create table stations (
eva int not null primary key,
ds100 varchar(16) not null,
name varchar(64) not null,
lat real not null,
lon real not null,
source smallint not null,
archived bool not null
);
update schema_version set version = 27;
update schema_version set iris = '0';
}
);
},
# v27 -> v28
# add ds100, name, and lat/lon from stations table to journeys_str / in_transit_str
sub {
my ($db) = @_;
$db->query(
qq{
drop view journeys_str;
drop view in_transit_str;
create view journeys_str as select
journeys.id as journey_id, user_id,
train_type, train_line, train_no, train_id,
extract(epoch from checkin_time) as checkin_ts,
extract(epoch from sched_departure) as sched_dep_ts,
extract(epoch from real_departure) as real_dep_ts,
checkin_station_id as dep_eva,
dep_station.ds100 as dep_ds100,
dep_station.name as dep_name,
dep_station.lat as dep_lat,
dep_station.lon as dep_lon,
extract(epoch from checkout_time) as checkout_ts,
extract(epoch from sched_arrival) as sched_arr_ts,
extract(epoch from real_arrival) as real_arr_ts,
checkout_station_id as arr_eva,
arr_station.ds100 as arr_ds100,
arr_station.name as arr_name,
arr_station.lat as arr_lat,
arr_station.lon as arr_lon,
polylines.polyline as polyline,
cancelled, edited, route, messages, user_data,
dep_platform, arr_platform
from journeys
left join polylines on polylines.id = polyline_id
left join stations as dep_station on checkin_station_id = dep_station.eva
left join stations as arr_station on checkout_station_id = arr_station.eva
;
create view in_transit_str as select
user_id,
train_type, train_line, train_no, train_id,
extract(epoch from checkin_time) as checkin_ts,
extract(epoch from sched_departure) as sched_dep_ts,
extract(epoch from real_departure) as real_dep_ts,
checkin_station_id as dep_eva,
dep_station.ds100 as dep_ds100,
dep_station.name as dep_name,
dep_station.lat as dep_lat,
dep_station.lon as dep_lon,
extract(epoch from checkout_time) as checkout_ts,
extract(epoch from sched_arrival) as sched_arr_ts,
extract(epoch from real_arrival) as real_arr_ts,
checkout_station_id as arr_eva,
arr_station.ds100 as arr_ds100,
arr_station.name as arr_name,
arr_station.lat as arr_lat,
arr_station.lon as arr_lon,
polylines.polyline as polyline,
cancelled, route, messages, user_data,
dep_platform, arr_platform, data
from in_transit
left join polylines on polylines.id = polyline_id
left join stations as dep_station on checkin_station_id = dep_station.eva
left join stations as arr_station on checkout_station_id = arr_station.eva
;
update schema_version set version = 28;
}
);
},
# v28 -> v29
# add pre-migration travelynx version. This way, a failed migration can
# print a helpful "git checkout" command.
sub {
my ($db) = @_;
$db->query(
qq{
alter table schema_version
add column travelynx varchar(64);
update schema_version set version = 29;
}
);
},
# v29 -> v30
# change layout of stops in in_transit and journeys "route" lists.
# Old layout: A mixture of [name, {data}, undef/"additional"/"cancelled"], [name, timestamp, timestamp], and [name]
# New layout: [name, eva, {data including isAdditional/isCancelled}]
# Combined with a maintenance task that adds eva IDs to past stops, this will allow for more resilience against station name changes.
# It will also help increase the performance of distance and map calculation
sub {
my ($db) = @_;
my $json = JSON->new;
say 'Adjusting route schema, this may take a while ...';
my $res = $db->select( 'in_transit_str', [ 'route', 'user_id' ] );
while ( my $row = $res->expand->hash ) {
my @new_route;
for my $stop ( @{ $row->{route} } ) {
push( @new_route, [ $stop->[0], undef, {} ] );
}
$db->update(
'in_transit',
{ route => $json->encode( \@new_route ) },
{ user_id => $row->{user_id} }
);
}
my $total
= $db->select( 'journeys', 'count(*) as count' )->hash->{count};
my $count = 0;
$res = $db->select( 'journeys_str', [ 'route', 'journey_id' ] );
while ( my $row = $res->expand->hash ) {
my @new_route;
for my $stop ( @{ $row->{route} } ) {
if ( @{$stop} == 1 ) {
push( @new_route, [ $stop->[0], undef, {} ] );
}
elsif (
( not defined $stop->[1] or $stop->[1] =~ m{ ^ \d+ $ }x )
and
( not defined $stop->[2] or $stop->[2] =~ m{ ^ \d+ $ }x )
)
{
push( @new_route, [ $stop->[0], undef, {} ] );
}
else {
my $attr = $stop->[1] // {};
if ( $stop->[2] and $stop->[2] eq 'additional' ) {
$attr->{isAdditional} = 1;
}
elsif ( $stop->[2] and $stop->[2] eq 'cancelled' ) {
$attr->{isCancelled} = 1;
}
push( @new_route, [ $stop->[0], undef, $attr ] );
}
}
$db->update(
'journeys',
{ route => $json->encode( \@new_route ) },
{ id => $row->{journey_id} }
);
if ( $count++ % 10000 == 0 ) {
printf( " %2.0f%% complete\n", $count * 100 / $total );
}
}
say ' done';
$db->query(
qq{
update schema_version set version = 30;
}
);
},
# v30 -> v31
# travelynx v1.29.17 introduces links to conflicting journeys.
# These require changes to statistics data.
sub {
my ($db) = @_;
$db->query(
qq{
truncate journey_stats;
update schema_version set version = 31;
}
);
},
# v31 -> v32
# travelynx v1.29.18 improves above-mentioned conflict links.
sub {
my ($db) = @_;
$db->query(
qq{
truncate journey_stats;
update schema_version set version = 32;
}
);
},
# v32 -> v33
# add optional per-status visibility that overrides global visibility
sub {
my ($db) = @_;
$db->query(
qq{
alter table journeys add column visibility smallint;
alter table in_transit add column visibility smallint;
drop view journeys_str;
drop view in_transit_str;
create view journeys_str as select
journeys.id as journey_id, user_id,
train_type, train_line, train_no, train_id,
extract(epoch from checkin_time) as checkin_ts,
extract(epoch from sched_departure) as sched_dep_ts,
extract(epoch from real_departure) as real_dep_ts,
checkin_station_id as dep_eva,
dep_station.ds100 as dep_ds100,
dep_station.name as dep_name,
dep_station.lat as dep_lat,
dep_station.lon as dep_lon,
extract(epoch from checkout_time) as checkout_ts,
extract(epoch from sched_arrival) as sched_arr_ts,
extract(epoch from real_arrival) as real_arr_ts,
checkout_station_id as arr_eva,
arr_station.ds100 as arr_ds100,
arr_station.name as arr_name,
arr_station.lat as arr_lat,
arr_station.lon as arr_lon,
polylines.polyline as polyline,
visibility,
cancelled, edited, route, messages, user_data,
dep_platform, arr_platform
from journeys
left join polylines on polylines.id = polyline_id
left join stations as dep_station on checkin_station_id = dep_station.eva
left join stations as arr_station on checkout_station_id = arr_station.eva
;
create view in_transit_str as select
user_id,
train_type, train_line, train_no, train_id,
extract(epoch from checkin_time) as checkin_ts,
extract(epoch from sched_departure) as sched_dep_ts,
extract(epoch from real_departure) as real_dep_ts,
checkin_station_id as dep_eva,
dep_station.ds100 as dep_ds100,
dep_station.name as dep_name,
dep_station.lat as dep_lat,
dep_station.lon as dep_lon,
extract(epoch from checkout_time) as checkout_ts,
extract(epoch from sched_arrival) as sched_arr_ts,
extract(epoch from real_arrival) as real_arr_ts,
checkout_station_id as arr_eva,
arr_station.ds100 as arr_ds100,
arr_station.name as arr_name,
arr_station.lat as arr_lat,
arr_station.lon as arr_lon,
polylines.polyline as polyline,
visibility,
cancelled, route, messages, user_data,
dep_platform, arr_platform, data
from in_transit
left join polylines on polylines.id = polyline_id
left join stations as dep_station on checkin_station_id = dep_station.eva
left join stations as arr_station on checkout_station_id = arr_station.eva
;
}
);
my $res = $db->select( 'users', [ 'id', 'public_level' ] );
while ( my $row = $res->hash ) {
my $old_level = $row->{public_level};
# status default: unlisted
my $new_level = 30;
if ( $old_level & 0x01 ) {
# status: account required
$new_level = 80;
}
if ( $old_level & 0x02 ) {
# status: public
$new_level = 100;
}
if ( $old_level & 0x04 ) {
# comment public
$new_level |= 0x80;
}
if ( $old_level & 0x10 ) {
# past: account required
$new_level |= 0x100;
}
if ( $old_level & 0x20 ) {
# past: public
$new_level |= 0x200;
}
if ( $old_level & 0x40 ) {
# past: infinite (default is 4 weeks)
$new_level |= 0x400;
}
my $r = $db->update(
'users',
{ public_level => $new_level },
{ id => $row->{id} }
)->rows;
if ( $r != 1 ) {
die("oh no");
}
}
$db->update( 'schema_version', { version => 33 } );
},
# v33 -> v34
# add polyline_id to in_transit_str
# (https://github.com/derf/travelynx/issues/66)
sub {
my ($db) = @_;
$db->query(
qq{
drop view in_transit_str;
create view in_transit_str as select
user_id,
train_type, train_line, train_no, train_id,
extract(epoch from checkin_time) as checkin_ts,
extract(epoch from sched_departure) as sched_dep_ts,
extract(epoch from real_departure) as real_dep_ts,
checkin_station_id as dep_eva,
dep_station.ds100 as dep_ds100,
dep_station.name as dep_name,
dep_station.lat as dep_lat,
dep_station.lon as dep_lon,
extract(epoch from checkout_time) as checkout_ts,
extract(epoch from sched_arrival) as sched_arr_ts,
extract(epoch from real_arrival) as real_arr_ts,
checkout_station_id as arr_eva,
arr_station.ds100 as arr_ds100,
arr_station.name as arr_name,
arr_station.lat as arr_lat,
arr_station.lon as arr_lon,
polyline_id,
polylines.polyline as polyline,
visibility,
cancelled, route, messages, user_data,
dep_platform, arr_platform, data
from in_transit
left join polylines on polylines.id = polyline_id
left join stations as dep_station on checkin_station_id = dep_station.eva
left join stations as arr_station on checkout_station_id = arr_station.eva
;
update schema_version set version = 34;
}
);
},
# v34 -> v35
sub {
my ($db) = @_;
# 1 : follows
# 2 : follow requested
# 3 : is blocked by
$db->query(
qq{
create table relations (
subject_id integer not null references users (id),
predicate smallint not null,
object_id integer not null references users (id),
primary key (subject_id, object_id)
);
create view followers as select
relations.object_id as self_id,
users.id as id,
users.name as name
from relations
join users on relations.subject_id = users.id
where predicate = 1;
create view followees as select
relations.subject_id as self_id,
users.id as id,
users.name as name
from relations
join users on relations.object_id = users.id
where predicate = 1;
create view follow_requests as select
relations.object_id as self_id,
users.id as id,
users.name as name
from relations
join users on relations.subject_id = users.id
where predicate = 2;
create view blocked_users as select
relations.object_id as self_id,
users.id as id,
users.name as name
from relations
join users on relations.subject_id = users.id
where predicate = 3;
update schema_version set version = 35;
}
);
},
# v35 -> v36
sub {
my ($db) = @_;
$db->query(
qq{
alter table relations
add column ts timestamptz not null;
alter table users
add column accept_follows smallint default 1;
update schema_version set version = 36;
}
);
},
# v36 -> v37
sub {
my ($db) = @_;
$db->query(
qq{
alter table users
add column notifications smallint default 0,
add column profile jsonb;
update schema_version set version = 37;
}
);
},
);
# TODO add 'hafas' column to in_transit (and maybe journeys? undo/redo needs something to work with...)
sub sync_stations {
my ( $db, $iris_version ) = @_;
$db->update( 'schema_version',
{ iris => $Travel::Status::DE::IRIS::Stations::VERSION } );
say 'Updating stations table, this may take a while ...';
my $total = scalar Travel::Status::DE::IRIS::Stations::get_stations();
my $count = 0;
for my $s ( Travel::Status::DE::IRIS::Stations::get_stations() ) {
my ( $ds100, $name, $eva, $lon, $lat ) = @{$s};
$db->insert(
'stations',
{
eva => $eva,
ds100 => $ds100,
name => $name,
lat => $lat,
lon => $lon,
source => 0,
archived => 0
},
{
on_conflict => \
'(eva) do update set archived = false, source = 0, ds100 = EXCLUDED.ds100, name=EXCLUDED.name, lat=EXCLUDED.lat, lon=EXCLUDED.lon'
}
);
if ( $count++ % 1000 == 0 ) {
printf( " %2.0f%% complete\n", $count * 100 / $total );
}
}
say ' done';
my $res1 = $db->query(
qq{
select checkin_station_id
from journeys
left join stations on journeys.checkin_station_id = stations.eva
where stations.eva is null
limit 1;
}
)->hash;
my $res2 = $db->query(
qq{
select checkout_station_id
from journeys
left join stations on journeys.checkout_station_id = stations.eva
where stations.eva is null
limit 1;
}
)->hash;
if ( $res1 or $res2 ) {
say 'Dropping stats cache for archived stations ...';
$db->query('truncate journey_stats;');
}
say 'Updating archived stations ...';
my $old_stations
= JSON->new->utf8->decode( scalar read_file('share/old_stations.json') );
for my $s ( @{$old_stations} ) {
$db->insert(
'stations',
{
eva => $s->{eva},
ds100 => $s->{ds100},
name => $s->{name},
lat => $s->{latlong}[0],
lon => $s->{latlong}[1],
source => 0,
archived => 1
},
{ on_conflict => undef }
);
}
if ( $iris_version == 0 ) {
say 'Applying EVA ID changes ...';
for my $change (
[ 721394, 301002, 'RKBP: Kronenplatz (U), Karlsruhe' ],
[
721356, 901012,
'RKME: Ettlinger Tor/Staatstheater (U), Karlsruhe'
],
)
{
my ( $old, $new, $desc ) = @{$change};
my $rows = $db->update(
'journeys',
{ checkout_station_id => $new },
{ checkout_station_id => $old }
)->rows;
$rows += $db->update(
'journeys',
{ checkin_station_id => $new },
{ checkin_station_id => $old }
)->rows;
if ($rows) {
say "$desc ($old -> $new) : $rows rows";
}
}
}
say 'Checking for unknown EVA IDs ...';
my $found = 0;
$res1 = $db->query(
qq{
select checkin_station_id
from journeys
left join stations on journeys.checkin_station_id = stations.eva
where stations.eva is null;
}
);
$res2 = $db->query(
qq{
select checkout_station_id
from journeys
left join stations on journeys.checkout_station_id = stations.eva
where stations.eva is null;
}
);
my %notified;
while ( my $row = $res1->hash ) {
my $eva = $row->{checkin_station_id};
if ( not $found ) {
$found = 1;
say '';
say '------------8<----------';
say 'Travel::Status::DE::IRIS v'
. $Travel::Status::DE::IRIS::Stations::VERSION;
}
if ( not $notified{$eva} ) {
say $eva;
$notified{$eva} = 1;
}
}
while ( my $row = $res2->hash ) {
my $eva = $row->{checkout_station_id};
if ( not $found ) {
$found = 1;
say '';
say '------------8<----------';
say 'Travel::Status::DE::IRIS v'
. $Travel::Status::DE::IRIS::Stations::VERSION;
}
if ( not $notified{$eva} ) {
say $eva;
$notified{$eva} = 1;
}
}
if ($found) {
say '------------8<----------';
say '';
say
'Due to a conceptual flaw in past travelynx releases, your database contains unknown EVA IDs.';
say
'Please file a bug report titled "Missing EVA IDs after DB migration" at https://github.com/derf/travelynx/issues';
say 'and include the list shown above in the bug report.';
say
'If you do not have a GitHub account, please send an E-Mail to derf+travelynx@finalrewind.org instead.';
say '';
say 'This issue does not affect usability or long-term data integrity,';
say 'and handling it is not time-critical.';
say
'Past journeys referencing unknown EVA IDs may have inaccurate distance statistics,';
say
'but this will be resolved once a future release handles those EVA IDs.';
say 'Note that this issue was already present in previous releases.';
}
else {
say 'None found.';
}
}
sub setup_db {
my ($db) = @_;
my $tx = $db->begin;
eval {
initialize_db($db);
$tx->commit;
};
if ($@) {
say "Database initialization failed: $@";
exit(1);
}
}
sub failure_hints {
my ($old_version) = @_;
say STDERR 'This travelynx instance has reached an undefined state:';
say STDERR
'The source code is expecting a different schema version than present in the database.';
say STDERR
'Please file a detailed bug report at <https://github.com/derf/travelynx/issues>';
say STDERR 'or send an e-mail to derf+travelynx@finalrewind.org.';
if ($old_version) {
say STDERR '';
say STDERR
"The last migration was performed with travelynx v${old_version}.";
say STDERR
'You may be able to return to a working state with the following command:';
say STDERR "git checkout ${old_version}";
say STDERR '';
say STDERR 'We apologize for any inconvenience.';
}
}
sub migrate_db {
my ( $self, $db ) = @_;
my $tx = $db->begin;
my $schema_version = get_schema_version($db);
say "Found travelynx schema v${schema_version}";
my $old_version;
if ( $schema_version >= 29 ) {
$old_version = get_schema_version( $db, 'travelynx' );
}
if ( $schema_version == @migrations ) {
say 'Database layout is up-to-date';
}
else {
eval {
for my $i ( $schema_version .. $#migrations ) {
printf( "Updating to v%d ...\n", $i + 1 );
$migrations[$i]($db);
}
say 'Update complete.';
};
if ($@) {
say STDERR "Migration failed: $@";
say STDERR "Rolling back to v${schema_version}";
failure_hints($old_version);
exit(1);
}
}
my $iris_version = get_schema_version( $db, 'iris' );
say "Found IRIS station database v${iris_version}";
if ( $iris_version eq $Travel::Status::DE::IRIS::Stations::VERSION ) {
say 'Station database is up-to-date';
}
else {
eval {
say
"Synchronizing with Travel::Status::DE::IRIS $Travel::Status::DE::IRIS::Stations::VERSION";
sync_stations( $db, $iris_version );
say 'Synchronization complete.';
};
if ($@) {
say STDERR "Synchronization failed: $@";
if ( $schema_version != @migrations ) {
say STDERR "Rolling back to v${schema_version}";
failure_hints($old_version);
}
exit(1);
}
}
$db->update( 'schema_version',
{ travelynx => $self->app->config->{version} } );
if ( get_schema_version($db) == @migrations ) {
$tx->commit;
say 'Changes committed to database. Have a nice day.';
}
else {
printf STDERR (
"Database schema mismatch after migrations: Expected %d, got %d\n",
scalar @migrations,
get_schema_version($db)
);
say STDERR "Rolling back to v${schema_version}";
say STDERR "";
failure_hints($old_version);
exit(1);
}
}
sub run {
my ( $self, $command ) = @_;
my $db = $self->app->pg->db;
#if ( not defined $dbh ) {
# printf( "Can't connect to the database: %s\n", $DBI::errstr );
# exit(1);
#}
if ( $command eq 'migrate' ) {
if ( not defined get_schema_version($db) ) {
setup_db($db);
}
$self->migrate_db($db);
}
elsif ( $command eq 'has-current-schema' ) {
if ( get_schema_version($db) == @migrations
and get_schema_version( $db, 'iris' ) eq
$Travel::Status::DE::IRIS::Stations::VERSION )
{
say "yes";
}
else {
say "no";
exit(1);
}
}
else {
$self->help;
}
}
1;
__END__
=head1 SYNOPSIS
Usage: index.pl database <migrate|has-current-schema>
Upgrades the database layout to the latest schema.
Recommended workflow:
> systemctl stop travelynx
> perl index.pl database migrate
> systemctl start travelynx
|