From fd78bb3a37a92df7a0074745dbd8d910775d208c Mon Sep 17 00:00:00 2001 From: Jannis R Date: Sun, 3 Nov 2024 16:22:25 +0100 Subject: [PATCH] =?UTF-8?q?arrivals=5Fdepartures:=20move=20arrival=5Fdepar?= =?UTF-8?q?ture=5Fid=20into=20separate=20view=20=E2=9A=A1=EF=B8=8F?= =?UTF-8?q?=F0=9F=92=A5?= MIME-Version: 1.0 Content-Type: text/plain; charset=UTF-8 Content-Transfer-Encoding: 8bit For the ID, we use frequencies_it, which we compute using a PARTITION BY. Because the latter is prohibitively slow, we move the entire computation into a separate view. Co-Authored-By: Holger Bruch --- lib/stop_times.js | 99 +++++++++++++++++++++++++---------------------- 1 file changed, 52 insertions(+), 47 deletions(-) diff --git a/lib/stop_times.js b/lib/stop_times.js index 2b0afdb..e3981af 100644 --- a/lib/stop_times.js +++ b/lib/stop_times.js @@ -262,46 +262,13 @@ WITH stop_times_based AS NOT MATERIALIZED ( ) -- stop_times-based arrivals/departures SELECT - ( - encode(trip_id::bytea, 'base64') - || ':' || encode(( - extract(ISOYEAR FROM "date") - || '-' || lpad(extract(MONTH FROM "date")::text, 2, '0') - || '-' || lpad(extract(DAY FROM "date")::text, 2, '0') - )::bytea, 'base64') - || ':' || encode((stop_sequence::text)::bytea, 'base64') - -- frequencies_row - || ':' || encode('-1'::bytea, 'base64') - -- frequencies_it - || ':' || encode('-1'::bytea, 'base64') - ) as arrival_departure_id, - stop_times_based.*, -- todo: expose local arrival/departure "wall clock time"? - -1 AS frequencies_row, - -1 AS frequencies_it + -1 AS frequencies_row FROM stop_times_based UNION ALL -- frequencies-based arrivals/departures -SELECT - ( - encode(trip_id::bytea, 'base64') - || ':' || encode(( - extract(ISOYEAR FROM "date") - || '-' || lpad(extract(MONTH FROM "date")::text, 2, '0') - || '-' || lpad(extract(DAY FROM "date")::text, 2, '0') - )::bytea, 'base64') - || ':' || encode((stop_sequence::text)::bytea, 'base64') - || ':' || encode((frequencies_row::text)::bytea, 'base64') - || ':' || encode((frequencies_it::text)::bytea, 'base64') - ) as arrival_departure_id, - * -FROM ( -SELECT - *, - row_number() OVER (PARTITION BY trip_id, "date", stop_sequence)::integer AS frequencies_it -FROM ( SELECT -- stop_times_based.* except t_arrival & t_departure, duh -- todo: find a way to use all columns without explicitly enumerating them here @@ -341,15 +308,52 @@ FROM ( FROM stop_times_based JOIN "${opt.schema}".frequencies ON frequencies.trip_id = stop_times_based.trip_id WHERE frequencies.exact_times = 'schedule_based' -- todo: is this correct? -) t -) t ) frequencies_based; +${opt.postgraphile ? `\ +-- todo: currently named arrivalsDeparture, should be arrivalDeparture (but allArrivalsDeparturesList!) +COMMENT ON COLUMN "${opt.schema}".arrivals_departures.route_short_name IS E'@omit'; +COMMENT ON COLUMN "${opt.schema}".arrivals_departures.route_long_name IS E'@omit'; +COMMENT ON COLUMN "${opt.schema}".arrivals_departures.route_type IS E'@omit'; +COMMENT ON COLUMN "${opt.schema}".arrivals_departures.direction_id IS E'@omit'; +COMMENT ON COLUMN "${opt.schema}".arrivals_departures.trip_headsign IS E'@omit'; +COMMENT ON COLUMN "${opt.schema}".arrivals_departures.stop_name IS E'@omit'; +COMMENT ON COLUMN "${opt.schema}".arrivals_departures.station_name IS E'@omit'; +-- > If you want to rename just one field or type, your best bet is to use a [@name] smart comment […]. +-- > NOTE: this still uses the inflectors, but it pretends that the tables name is different, so the input to the inflectors differs. +-- https://www.graphile.org/postgraphile/inflection/#overriding-naming---one-off +COMMENT ON VIEW "${opt.schema}".arrivals_departures IS E'@name arrival_departures\\n@primaryKey trip_id,date,stop_sequence,frequencies_row,frequencies_it\\n@foreignKey (route_id) references routes|@fieldName route\\n@foreignKey (trip_id) references trips|@fieldName trip\\n@foreignKey (stop_id) references stops|@fieldName stop\\n@foreignKey (station_id) references stops|@fieldName station'; +` : ''} + +CREATE OR REPLACE VIEW "${opt.schema}".arrivals_departures_with_ids AS +SELECT + *, + ( + encode(trip_id::bytea, 'base64') + || ':' || encode(( + extract(ISOYEAR FROM "date") + || '-' || lpad(extract(MONTH FROM "date")::text, 2, '0') + || '-' || lpad(extract(DAY FROM "date")::text, 2, '0') + )::bytea, 'base64') + || ':' || encode((stop_sequence::text)::bytea, 'base64') + || ':' || encode((frequencies_row::text)::bytea, 'base64') + || ':' || encode((frequencies_it::text)::bytea, 'base64') + ) as arrival_departure_id +FROM ( + SELECT + *, + (CASE WHEN frequencies_row = -1 + THEN -1 + ELSE row_number() OVER (PARTITION BY trip_id, "date", stop_sequence)::integer + END) AS frequencies_it + FROM "${opt.schema}".arrivals_departures +) t; + CREATE OR REPLACE FUNCTION "${opt.schema}".arrival_departure_by_arrival_departure_id(id TEXT) -RETURNS "${opt.schema}".arrivals_departures +RETURNS "${opt.schema}".arrivals_departures_with_ids AS $$ SELECT * - FROM "${opt.schema}".arrivals_departures + FROM "${opt.schema}".arrivals_departures_with_ids WHERE trip_id = convert_from(decode(split_part(id, ':', 1), 'base64'), 'UTF-8')::text AND "date" = (convert_from(decode(split_part(id, ':', 2), 'base64'), 'UTF-8')::text)::timestamp AND stop_sequence = (convert_from(decode(split_part(id, ':', 3), 'base64'), 'UTF-8')::text)::integer @@ -360,18 +364,19 @@ AS $$ $$ LANGUAGE SQL STABLE STRICT; ${opt.postgraphile ? `\ --- todo: currently named arrivalsDeparture, should be arrivalDeparture (but allArrivalsDeparturesList!) -COMMENT ON COLUMN "${opt.schema}".arrivals_departures.route_short_name IS E'@omit'; -COMMENT ON COLUMN "${opt.schema}".arrivals_departures.route_long_name IS E'@omit'; -COMMENT ON COLUMN "${opt.schema}".arrivals_departures.route_type IS E'@omit'; -COMMENT ON COLUMN "${opt.schema}".arrivals_departures.direction_id IS E'@omit'; -COMMENT ON COLUMN "${opt.schema}".arrivals_departures.trip_headsign IS E'@omit'; -COMMENT ON COLUMN "${opt.schema}".arrivals_departures.stop_name IS E'@omit'; -COMMENT ON COLUMN "${opt.schema}".arrivals_departures.station_name IS E'@omit'; +-- todo: DRY with comments on arrivals_departures +-- todo: what is the graphql field name? postgraphile singularifies most names +COMMENT ON COLUMN "${opt.schema}".arrivals_departures_with_ids.route_short_name IS E'@omit'; +COMMENT ON COLUMN "${opt.schema}".arrivals_departures_with_ids.route_long_name IS E'@omit'; +COMMENT ON COLUMN "${opt.schema}".arrivals_departures_with_ids.route_type IS E'@omit'; +COMMENT ON COLUMN "${opt.schema}".arrivals_departures_with_ids.direction_id IS E'@omit'; +COMMENT ON COLUMN "${opt.schema}".arrivals_departures_with_ids.trip_headsign IS E'@omit'; +COMMENT ON COLUMN "${opt.schema}".arrivals_departures_with_ids.stop_name IS E'@omit'; +COMMENT ON COLUMN "${opt.schema}".arrivals_departures_with_ids.station_name IS E'@omit'; -- > If you want to rename just one field or type, your best bet is to use a [@name] smart comment […]. -- > NOTE: this still uses the inflectors, but it pretends that the tables name is different, so the input to the inflectors differs. -- https://www.graphile.org/postgraphile/inflection/#overriding-naming---one-off -COMMENT ON VIEW "${opt.schema}".arrivals_departures IS E'@name arrival_departures\\n@primaryKey trip_id,date,stop_sequence,frequencies_row,frequencies_it\\n@foreignKey (route_id) references routes|@fieldName route\\n@foreignKey (trip_id) references trips|@fieldName trip\\n@foreignKey (stop_id) references stops|@fieldName stop\\n@foreignKey (station_id) references stops|@fieldName station'; +COMMENT ON VIEW "${opt.schema}".arrivals_departures_with_ids IS E'@name arrivals_departures_with_ids\\n@primaryKey trip_id,date,stop_sequence,frequencies_row,frequencies_it\\n@foreignKey (route_id) references routes|@fieldName route\\n@foreignKey (trip_id) references trips|@fieldName trip\\n@foreignKey (stop_id) references stops|@fieldName stop\\n@foreignKey (station_id) references stops|@fieldName station'; ` : ''} CREATE OR REPLACE VIEW "${opt.schema}".connections AS