Skip to content

Commit

Permalink
connections: move connection_id into separate view ⚡💥
Browse files Browse the repository at this point in the history
  • Loading branch information
derhuerst committed Nov 4, 2024
1 parent ba0beb4 commit cd885bf
Showing 1 changed file with 51 additions and 45 deletions.
96 changes: 51 additions & 45 deletions lib/stop_times.js
Original file line number Diff line number Diff line change
Expand Up @@ -508,40 +508,13 @@ WITH stop_times_based AS NOT MATERIALIZED (
)
-- stop_times-based connections
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((from_stop_sequence::text)::bytea, 'base64')
-- frequencies_row
|| ':' || encode('-1'::bytea, 'base64')
-- frequencies_it
|| ':' || encode('-1'::bytea, 'base64')
) as connection_id,
stop_times_based.*,
-1 AS frequencies_row,
-1 AS frequencies_it
-1 AS frequencies_row
FROM stop_times_based
UNION ALL
-- frequencies-based connections
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((from_stop_sequence::text)::bytea, 'base64')
|| ':' || encode((frequencies_row::text)::bytea, 'base64')
|| ':' || encode((frequencies_it::text)::bytea, 'base64')
) as connection_id,
-- stop_times_based.* except t_arrival & t_departure, duh
-- todo: find a way to use all columns without explicitly enumerating them here
route_id, route_short_name, route_long_name, route_type,
Expand Down Expand Up @@ -591,26 +564,60 @@ SELECT
to_station_name,
to_wheelchair_boarding,
frequencies_row,
frequencies_it
frequencies_row
FROM (
SELECT
stop_times_based.*,
frequencies.start_time,
frequencies.end_time,
frequencies.headway_secs,
frequencies_row,
(row_number() OVER (PARTITION BY stop_times_based.trip_id, "date", frequencies_row ORDER BY from_stop_sequence))::integer as frequencies_it
frequencies_row
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?
) frequencies_based;
${opt.postgraphile ? `\
-- todo: allow filtering based on stop and/or route and/or trip and/or time frame
-- https://www.graphile.org/postgraphile/functions/#setof-functions---connections
COMMENT ON COLUMN "${opt.schema}".connections.route_short_name IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections.route_long_name IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections.route_type IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections.direction_id IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections.trip_headsign IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections.from_stop_name IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections.from_station_name IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections.to_stop_name IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections.to_station_name IS E'@omit';
COMMENT ON VIEW "${opt.schema}".connections IS E'@primaryKey trip_id,date,from_stop_sequence,frequencies_row,frequencies_it\\n@foreignKey (route_id) references routes|@fieldName route\\n@foreignKey (trip_id) references trips|@fieldName trip\\n@foreignKey (from_stop_id) references stops|@fieldName fromStop\\n@foreignKey (from_station_id) references stops|@fieldName fromStation\\n@foreignKey (to_stop_id) references stops|@fieldName toStop\\n@foreignKey (to_station_id) references stops|@fieldName toStation';
` : ''}
CREATE VIEW "${opt.schema}".connections_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((from_stop_sequence::text)::bytea, 'base64')
|| ':' || encode((frequencies_row::text)::bytea, 'base64')
|| ':' || encode((frequencies_it::text)::bytea, 'base64')
) as connection_id,
*
FROM (
SELECT
*,
(row_number() OVER (PARTITION BY trip_id, "date", frequencies_row ORDER BY from_stop_sequence))::integer as frequencies_it
FROM "${opt.schema}".connections
) t;
CREATE OR REPLACE FUNCTION "${opt.schema}".connection_by_connection_id(id TEXT)
RETURNS "${opt.schema}".connections
RETURNS "${opt.schema}".connections_with_ids
AS $$
SELECT *
FROM "${opt.schema}".connections
FROM "${opt.schema}".connections_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 from_stop_sequence = (convert_from(decode(split_part(id, ':', 3), 'base64'), 'UTF-8')::text)::integer
Expand All @@ -621,19 +628,18 @@ AS $$
$$ LANGUAGE SQL STABLE STRICT;
${opt.postgraphile ? `\
-- todo: currently named arrivalsDeparture, should be arrivalDeparture (but allArrivalsDeparturesList!)
-- todo: allow filtering based on stop and/or route and/or trip and/or time frame
-- https://www.graphile.org/postgraphile/functions/#setof-functions---connections
COMMENT ON COLUMN "${opt.schema}".connections.route_short_name IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections.route_long_name IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections.route_type IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections.direction_id IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections.trip_headsign IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections.from_stop_name IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections.from_station_name IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections.to_stop_name IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections.to_station_name IS E'@omit';
COMMENT ON VIEW "${opt.schema}".connections IS E'@primaryKey trip_id,date,from_stop_sequence,frequencies_row,frequencies_it\\n@foreignKey (route_id) references routes|@fieldName route\\n@foreignKey (trip_id) references trips|@fieldName trip\\n@foreignKey (from_stop_id) references stops|@fieldName fromStop\\n@foreignKey (from_station_id) references stops|@fieldName fromStation\\n@foreignKey (to_stop_id) references stops|@fieldName toStop\\n@foreignKey (to_station_id) references stops|@fieldName toStation';
COMMENT ON COLUMN "${opt.schema}".connections_with_ids.route_short_name IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections_with_ids.route_long_name IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections_with_ids.route_type IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections_with_ids.direction_id IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections_with_ids.trip_headsign IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections_with_ids.from_stop_name IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections_with_ids.from_station_name IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections_with_ids.to_stop_name IS E'@omit';
COMMENT ON COLUMN "${opt.schema}".connections_with_ids.to_station_name IS E'@omit';
COMMENT ON VIEW "${opt.schema}".connections_with_ids IS E'@primaryKey trip_id,date,from_stop_sequence,frequencies_row,frequencies_it\\n@foreignKey (route_id) references routes|@fieldName route\\n@foreignKey (trip_id) references trips|@fieldName trip\\n@foreignKey (from_stop_id) references stops|@fieldName fromStop\\n@foreignKey (from_station_id) references stops|@fieldName fromStation\\n@foreignKey (to_stop_id) references stops|@fieldName toStop\\n@foreignKey (to_station_id) references stops|@fieldName toStation';
` : ''}
`

Expand Down

0 comments on commit cd885bf

Please sign in to comment.