diff options
author | Derf Null <derf@finalrewind.org> | 2023-06-26 20:53:08 +0200 |
---|---|---|
committer | Derf Null <derf@finalrewind.org> | 2023-06-26 20:53:08 +0200 |
commit | 8cb0de1b702eda1c8fb5b6ed795d769822999d75 (patch) | |
tree | aa3a93ab0fd8ebdabb60daef6468bacaa6090cfe /lib/Travelynx/Command | |
parent | f0be693811bdba2f7a1328944c7820353f392cff (diff) |
compute effective visibility in database view
Diffstat (limited to 'lib/Travelynx/Command')
-rw-r--r-- | lib/Travelynx/Command/database.pm | 74 |
1 files changed, 74 insertions, 0 deletions
diff --git a/lib/Travelynx/Command/database.pm b/lib/Travelynx/Command/database.pm index d15330d..b0ce0f5 100644 --- a/lib/Travelynx/Command/database.pm +++ b/lib/Travelynx/Command/database.pm @@ -1643,6 +1643,80 @@ my @migrations = ( } $db->update( 'schema_version', { version => 40 } ); }, + + # v40 -> v41 + # Compute effective visibility in in_transit_str and journeys_str. + sub { + my ($db) = @_; + $db->query( + qq{ + drop view in_transit_str; + drop view journeys_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, + 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 + left join stations as arr_station on checkout_station_id = arr_station.eva + ; + 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, + 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 + left join stations as arr_station on checkout_station_id = arr_station.eva + ; + update schema_version set version = 41; + } + ); + }, ); # TODO add 'hafas' column to in_transit (and maybe journeys? undo/redo needs something to work with...) |