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
|
package Travelynx::Command::database;
use Mojo::Base 'Mojolicious::Command';
use DateTime;
has description => 'Initialize or upgrade database layout';
has usage => sub { shift->extract_usage };
sub get_schema_version {
my ($dbh) = @_;
# We do not want DBD to print an SQL error if schema_version does not
# exist, as this is not an error in this case. Setting $dbh->{PrintError} =
# 0 would disable error printing for all subsequent SQL operations, however,
# we only want to disable it for this specific query. Hence we use a
# prepared statement and only disable error printing only there.
my $sth = $dbh->prepare(qq{select version from schema_version});
$sth->{PrintError} = 0;
my $success = $sth->execute;
if ( not defined $success ) {
return undef;
}
my $rows = $sth->fetchall_arrayref;
if ( @{$rows} == 1 ) {
return $rows->[0][0];
}
else {
printf( "Found multiple schema versions: %s", @{$rows} );
exit(1);
}
}
sub initialize_db {
my ($dbh) = @_;
return $dbh->do(
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 ($dbh) = @_;
return $dbh->do(
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 ($dbh) = @_;
return $dbh->do(
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 ($dbh) = @_;
return $dbh->do(
qq{
truncate journey_stats;
update schema_version set version = 3;
}
);
},
);
sub setup_db {
my ($dbh) = @_;
$dbh->begin_work;
if ( initialize_db($dbh) ) {
$dbh->commit;
}
else {
$dbh->rollback;
printf( "Database initialization was not successful: %s",
$DBI::errstr );
}
}
sub migrate_db {
my ($dbh) = @_;
$dbh->begin_work;
my $schema_version = get_schema_version($dbh);
say "Found travelynx schema v${schema_version}";
if ( $schema_version == @migrations ) {
say "Database layout is up-to-date";
}
for my $i ( $schema_version .. $#migrations ) {
printf( "Updating to v%d ...\n", $i + 1 );
if ( not $migrations[$i]($dbh) ) {
say "Aborting migration; rollback to v${schema_version}";
$dbh->rollback;
exit(1);
}
}
if ( get_schema_version($dbh) == @migrations ) {
$dbh->commit;
}
}
sub run {
my ( $self, $command ) = @_;
my $dbh = $self->app->dbh;
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($dbh) ) {
setup_db($dbh);
}
migrate_db($dbh);
}
elsif ( $command eq 'has-current-schema' ) {
if ( get_schema_version($dbh) == @migrations ) {
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 migrate
> systemctl start travelynx
|