summaryrefslogtreecommitdiff
path: root/lib/Travelynx/Command/database.pm
diff options
context:
space:
mode:
Diffstat (limited to 'lib/Travelynx/Command/database.pm')
-rw-r--r--lib/Travelynx/Command/database.pm214
1 files changed, 212 insertions, 2 deletions
diff --git a/lib/Travelynx/Command/database.pm b/lib/Travelynx/Command/database.pm
index d0bc163..0e87b2a 100644
--- a/lib/Travelynx/Command/database.pm
+++ b/lib/Travelynx/Command/database.pm
@@ -1,6 +1,7 @@
package Travelynx::Command::database;
# Copyright (C) 2020-2023 Birte Kristina Friesel
+# Copyright (C) 2025 networkException <git@nwex.de>
#
# SPDX-License-Identifier: AGPL-3.0-or-later
use Mojo::Base 'Mojolicious::Command';
@@ -11,6 +12,7 @@ use List::Util qw();
use JSON;
use Travel::Status::DE::HAFAS;
use Travel::Status::DE::IRIS::Stations;
+use Travel::Status::MOTIS;
has description => 'Initialize or upgrade database layout';
@@ -2854,6 +2856,173 @@ qq{select distinct checkout_station_id from in_transit where backend_id = 0;}
}
);
},
+
+ # v61 -> v62
+ # Add MOTIS backend type, add RNV and transitous MOTIS backends
+ sub {
+ my ($db) = @_;
+ $db->query(
+ qq{
+ alter table backends add column motis bool default false;
+ alter table schema_version add column motis varchar(12);
+
+ create table stations_external_ids (
+ eva serial not null primary key,
+ backend_id smallint not null,
+ external_id text not null,
+
+ unique (backend_id, external_id),
+ foreign key (eva, backend_id) references stations (eva, source)
+ );
+
+ 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
+ ;
+
+ drop view in_transit_str;
+ drop view journeys_str;
+ drop view users_with_backend;
+ drop view follows_in_transit;
+
+ 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
+ ;
+ }
+ );
+ $db->query(
+ qq{
+ update schema_version set version = 62;
+ }
+ );
+ },
);
sub sync_stations {
@@ -3044,7 +3213,7 @@ sub sync_stations {
}
}
-sub sync_backends {
+sub sync_backends_hafas {
my ($db) = @_;
for my $service ( Travel::Status::DE::HAFAS::get_services() ) {
my $present = $db->select(
@@ -3074,6 +3243,36 @@ sub sync_backends {
{ hafas => $Travel::Status::DE::HAFAS::VERSION } );
}
+sub sync_backends_motis {
+ my ($db) = @_;
+ for my $service ( Travel::Status::MOTIS::get_services() ) {
+ my $present = $db->select(
+ 'backends',
+ 'count(*) as count',
+ {
+ motis => 1,
+ name => $service->{shortname}
+ }
+ )->hash->{count};
+ if ( not $present ) {
+ $db->insert(
+ 'backends',
+ {
+ iris => 0,
+ hafas => 0,
+ efa => 0,
+ dbris => 0,
+ motis => 1,
+ name => $service->{shortname},
+ },
+ { on_conflict => undef }
+ );
+ }
+ }
+
+ $db->update( 'schema_version', { motis => $Travel::Status::MOTIS::VERSION } );
+}
+
sub setup_db {
my ($db) = @_;
my $tx = $db->begin;
@@ -3169,7 +3368,18 @@ sub migrate_db {
else {
say
"Synchronizing with Travel::Status::DE::HAFAS $Travel::Status::DE::HAFAS::VERSION";
- sync_backends($db);
+ sync_backends_hafas($db);
+ }
+
+ my $motis_version = get_schema_version( $db, 'motis' ) // '0';
+ say "Found backend table for Motis v${motis_version}";
+ if ( $motis_version eq $Travel::Status::MOTIS::VERSION ) {
+ say 'Backend table is up-to-date';
+ }
+ else {
+ say
+"Synchronizing with Travel::Status::MOTIS $Travel::Status::MOTIS::VERSION";
+ sync_backends_motis($db);
}
$db->update( 'schema_version',