diff options
Diffstat (limited to 'lib/Travelynx/Command/database.pm')
| -rw-r--r-- | lib/Travelynx/Command/database.pm | 416 |
1 files changed, 415 insertions, 1 deletions
diff --git a/lib/Travelynx/Command/database.pm b/lib/Travelynx/Command/database.pm index 95d67f5..5792e5f 100644 --- a/lib/Travelynx/Command/database.pm +++ b/lib/Travelynx/Command/database.pm @@ -7,7 +7,7 @@ package Travelynx::Command::database; use Mojo::Base 'Mojolicious::Command'; use DateTime; -use File::Slurp qw(read_file); +use File::Slurp qw(read_dir read_file); use List::Util qw(); use JSON; use Travel::Status::DE::EFA; @@ -3208,8 +3208,422 @@ qq{select distinct checkout_station_id from in_transit where backend_id = 0;} } ); }, + + # v65 -> v66 + # Relax platform and line length constraints for EFA APIs (and possibly MOTIS) + sub { + my ($db) = @_; + $db->query( + qq{ + drop view in_transit_str; + drop view journeys_str; + drop view users_with_backend; + drop view follows_in_transit; + + alter table in_transit alter column train_line type varchar(64); + alter table in_transit alter column arr_platform type varchar(64); + alter table in_transit alter column dep_platform type varchar(64); + alter table journeys alter column train_line type varchar(64); + alter table journeys alter column arr_platform type varchar(64); + alter table journeys alter column dep_platform type varchar(64); + + create view in_transit_str as select + user_id, + backend.iris as is_iris, backend.hafas as is_hafas, + backend.efa as is_efa, backend.dbris as is_dbris, + backend.motis as is_motis, + backend.name as backend_name, in_transit.backend_id as backend_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, + dep_station_external_id.external_id as dep_external_id, + 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, + arr_station_external_id.external_id as arr_external_id, + polyline_id, + polylines.polyline as polyline, + visibility, + coalesce(visibility, users.public_level & 127) as effective_visibility, + cancelled, route, messages, user_data, + dep_platform, arr_platform, data + from in_transit + left join polylines on polylines.id = polyline_id + left join users on users.id = user_id + left join stations as dep_station on checkin_station_id = dep_station.eva and in_transit.backend_id = dep_station.source + left join stations as arr_station on checkout_station_id = arr_station.eva and in_transit.backend_id = arr_station.source + left join stations_external_ids as dep_station_external_id on checkin_station_id = dep_station_external_id.eva and in_transit.backend_id = dep_station_external_id.backend_id + left join stations_external_ids as arr_station_external_id on checkout_station_id = arr_station_external_id.eva and in_transit.backend_id = arr_station_external_id.backend_id + left join backends as backend on in_transit.backend_id = backend.id + ; + create view journeys_str as select + journeys.id as journey_id, user_id, + backend.iris as is_iris, backend.hafas as is_hafas, + backend.efa as is_efa, backend.dbris as is_dbris, + backend.motis as is_motis, + backend.name as backend_name, journeys.backend_id as backend_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, + dep_station_external_id.external_id as dep_external_id, + 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, + arr_station_external_id.external_id as arr_external_id, + polylines.polyline as polyline, + visibility, + coalesce(visibility, users.public_level & 127) as effective_visibility, + cancelled, edited, route, messages, user_data, + dep_platform, arr_platform + from journeys + left join polylines on polylines.id = polyline_id + left join users on users.id = user_id + left join stations as dep_station on checkin_station_id = dep_station.eva and journeys.backend_id = dep_station.source + left join stations as arr_station on checkout_station_id = arr_station.eva and journeys.backend_id = arr_station.source + left join stations_external_ids as dep_station_external_id on checkin_station_id = dep_station_external_id.eva and journeys.backend_id = dep_station_external_id.backend_id + left join stations_external_ids as arr_station_external_id on checkout_station_id = arr_station_external_id.eva and journeys.backend_id = arr_station_external_id.backend_id + left join backends as backend on journeys.backend_id = backend.id + ; + create view users_with_backend as select + users.id as id, users.name as name, status, public_level, + email, password, registered_at, last_seen, + deletion_requested, deletion_notified, use_history, + accept_follows, notifications, profile, backend_id, iris, + hafas, efa, dbris, motis, backend.name as backend_name + from users + left join backends as backend on users.backend_id = backend.id + ; + create view follows_in_transit as select + r1.subject_id as follower_id, user_id as followee_id, + users.name as followee_name, + train_type, train_line, train_no, train_id, + backend.iris as is_iris, backend.hafas as is_hafas, + backend.efa as is_efa, backend.dbris as is_dbris, + backend.motis as is_motis, + backend.name as backend_name, in_transit.backend_id as backend_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, + coalesce(visibility, users.public_level & 127) as effective_visibility, + cancelled, route, messages, user_data, + dep_platform, arr_platform, data + from in_transit + left join polylines on polylines.id = polyline_id + left join users on users.id = user_id + left join relations as r1 on r1.predicate = 1 and r1.object_id = user_id + left join stations as dep_station on checkin_station_id = dep_station.eva and in_transit.backend_id = dep_station.source + left join stations as arr_station on checkout_station_id = arr_station.eva and in_transit.backend_id = arr_station.source + left join backends as backend on in_transit.backend_id = backend.id + order by checkin_time desc + ; + + update schema_version set version = 66; + } + ); + }, + + # v66 -> v67 + # Add language settings to profile + sub { + my ($db) = @_; + $db->query( + qq{ + drop view users_with_backend; + alter table users add column language varchar(128); + update schema_version set version = 67; + create view users_with_backend as select + users.id as id, users.name as name, status, public_level, + language, email, password, registered_at, last_seen, + deletion_requested, deletion_notified, use_history, + accept_follows, notifications, profile, backend_id, iris, + hafas, efa, dbris, motis, backend.name as backend_name + from users + left join backends as backend on users.backend_id = backend.id + ; + } + ); + }, + + # v67 -> v68 + # Of course there are backends with stop names that are >64 chars long + sub { + my ($db) = @_; + $db->query( + qq{ + drop view stations_str; + drop view stations_with_external_ids; + drop view in_transit_str; + drop view journeys_str; + drop view follows_in_transit; + alter table stations alter column name type varchar(128); + create view stations_str as + select stations.name as name, + eva, lat, lon, + backends.name as backend, + dbris as is_dbris, + efa as is_efa, + iris as is_iris, + hafas as is_hafas, + motis as is_motis + from stations + left join backends + on source = backends.id; + create view stations_with_external_ids as select + stations.*, stations_external_ids.external_id + from stations + left join stations_external_ids on + stations.eva = stations_external_ids.eva and + stations.source = stations_external_ids.backend_id + ; + create view in_transit_str as select + user_id, + backend.iris as is_iris, backend.hafas as is_hafas, + backend.efa as is_efa, backend.dbris as is_dbris, + backend.motis as is_motis, + backend.name as backend_name, in_transit.backend_id as backend_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, + dep_station_external_id.external_id as dep_external_id, + 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, + arr_station_external_id.external_id as arr_external_id, + polyline_id, + polylines.polyline as polyline, + visibility, + coalesce(visibility, users.public_level & 127) as effective_visibility, + cancelled, route, messages, user_data, + dep_platform, arr_platform, data + from in_transit + left join polylines on polylines.id = polyline_id + left join users on users.id = user_id + left join stations as dep_station on checkin_station_id = dep_station.eva and in_transit.backend_id = dep_station.source + left join stations as arr_station on checkout_station_id = arr_station.eva and in_transit.backend_id = arr_station.source + left join stations_external_ids as dep_station_external_id on checkin_station_id = dep_station_external_id.eva and in_transit.backend_id = dep_station_external_id.backend_id + left join stations_external_ids as arr_station_external_id on checkout_station_id = arr_station_external_id.eva and in_transit.backend_id = arr_station_external_id.backend_id + left join backends as backend on in_transit.backend_id = backend.id + ; + create view journeys_str as select + journeys.id as journey_id, user_id, + backend.iris as is_iris, backend.hafas as is_hafas, + backend.efa as is_efa, backend.dbris as is_dbris, + backend.motis as is_motis, + backend.name as backend_name, journeys.backend_id as backend_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, + dep_station_external_id.external_id as dep_external_id, + 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, + arr_station_external_id.external_id as arr_external_id, + polylines.polyline as polyline, + visibility, + coalesce(visibility, users.public_level & 127) as effective_visibility, + cancelled, edited, route, messages, user_data, + dep_platform, arr_platform + from journeys + left join polylines on polylines.id = polyline_id + left join users on users.id = user_id + left join stations as dep_station on checkin_station_id = dep_station.eva and journeys.backend_id = dep_station.source + left join stations as arr_station on checkout_station_id = arr_station.eva and journeys.backend_id = arr_station.source + left join stations_external_ids as dep_station_external_id on checkin_station_id = dep_station_external_id.eva and journeys.backend_id = dep_station_external_id.backend_id + left join stations_external_ids as arr_station_external_id on checkout_station_id = arr_station_external_id.eva and journeys.backend_id = arr_station_external_id.backend_id + left join backends as backend on journeys.backend_id = backend.id + ; + create view follows_in_transit as select + r1.subject_id as follower_id, user_id as followee_id, + users.name as followee_name, + train_type, train_line, train_no, train_id, + backend.iris as is_iris, backend.hafas as is_hafas, + backend.efa as is_efa, backend.dbris as is_dbris, + backend.motis as is_motis, + backend.name as backend_name, in_transit.backend_id as backend_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, + coalesce(visibility, users.public_level & 127) as effective_visibility, + cancelled, route, messages, user_data, + dep_platform, arr_platform, data + from in_transit + left join polylines on polylines.id = polyline_id + left join users on users.id = user_id + left join relations as r1 on r1.predicate = 1 and r1.object_id = user_id + left join stations as dep_station on checkin_station_id = dep_station.eva and in_transit.backend_id = dep_station.source + left join stations as arr_station on checkout_station_id = arr_station.eva and in_transit.backend_id = arr_station.source + left join backends as backend on in_transit.backend_id = backend.id + order by checkin_time desc + ; + update schema_version set version = 68; + } + ); + }, + + # v68 -> v69 + # Incorporate dbdb (entry/exit direction) data into travelynx + # This avoids having to make web requests to lib.finalrewind.org/dbdb, + # and allows for also showing the exit direction for intermediate stops. + sub { + my ($db) = @_; + $db->query( + qq{ + alter table schema_version + add column dbdb varchar(12); + create table bahn_platform_directions ( + eva integer primary key, + data jsonb not null + ); + } + ); + sync_dbdb($db); + $db->query( + qq{ + update schema_version set version = 69; + update schema_version set dbdb = '2025-10-27'; + } + ); + }, ); +sub sync_dbdb { + my ($db) = @_; + + my $json = JSON->new; + + for my $file ( read_dir( 'ext/dbdb/s', prefix => 1 ) ) { + if ( $file !~ m{\.txt$} ) { + next; + } + + my %station; + for my $line ( read_file( $file, { binmode => ':encoding(utf-8)' } ) ) { + if ( $line + =~ m{ ^ \s* (?<platform> \d+ ) \s+ (?<type> \S+ ) \s+ (?<direction> \S+ ) }x + ) + { + $station{ $+{platform} } = { + kopfgleis => $+{type} eq 'K' ? \1 : \0, + direction => $+{direction}, + }; + } + elsif ( $line + =~ m{ ^ @ \s* (?<stations> [^:]+ ) : \s* (?<platforms> .+ ) $ }x + ) + { + my $stations_raw = $+{stations}; + my $platforms_raw = $+{platforms}; + my @stations = split( qr{, }, $stations_raw ); + my @platforms = split( qr{, }, $platforms_raw ); + for my $platform (@platforms) { + my ( $number, $direction ) = split( qr{ }, $platform ); + for my $from_station (@stations) { + $station{$number}{direction_from}{$from_station} + = $direction; + } + } + } + } + my ($station_name) = ( $file =~ m{ s / ([^.]*) . txt $ }x ); + my ($station) + = Travel::Status::DE::IRIS::Stations::get_station($station_name); + if ( $station and $station->[0] eq $station_name ) { + $db->insert( + 'bahn_platform_directions', + { + eva => $station->[2], + data => $json->encode( \%station ) + }, + { on_conflict => \'(eva) do update set data = EXCLUDED.data' } + ); + } + elsif ( not $station ) { + say STDERR "DBDB import: unknown station: $station_name"; + } + else { + say STDERR +"DBDB import: station mismatch: wanted to import $station_name, but got " + . $station->[0]; + } + } +} + sub sync_stations { my ( $db, $iris_version ) = @_; |
