Unverified Commit 24a01da9 authored by Birte Kristina Friesel's avatar Birte Kristina Friesel
Browse files

database: Relax platform and line length constraints

Closes #267
parent 2f3d6492
Loading
Loading
Loading
Loading
+151 −0
Original line number Diff line number Diff line
@@ -3208,6 +3208,157 @@ 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;
			}
		);
	},
);

sub sync_stations {