DB-backed bus stalking pretty much done.
This commit is contained in:
parent
2372ac0dd9
commit
e6c88fe7e6
|
@ -7,6 +7,7 @@ CREATE EXTENSION IF NOT EXISTS "pg_net" SCHEMA extensions;
|
||||||
-- then second cron job updates from net._http_response table.
|
-- then second cron job updates from net._http_response table.
|
||||||
create table if not exists raw_bus_positions (
|
create table if not exists raw_bus_positions (
|
||||||
request_id int not null,
|
request_id int not null,
|
||||||
|
created timestamp with time zone not null default now(),
|
||||||
response_status int null,
|
response_status int null,
|
||||||
response_json jsonb null
|
response_json jsonb null
|
||||||
);
|
);
|
||||||
|
@ -55,12 +56,11 @@ create or replace function create_api_url(bus_routes text[]) returns text langua
|
||||||
$$;
|
$$;
|
||||||
|
|
||||||
create or replace function gather_bus_data()
|
create or replace function gather_bus_data()
|
||||||
returns int language sql
|
returns void language sql
|
||||||
as $$
|
as $$
|
||||||
select
|
insert into raw_bus_positions (request_id) select
|
||||||
net.http_get(
|
net.http_get(
|
||||||
url := create_api_url(array['1', '2', '3']),
|
url := create_api_url(array['1', '2', '3']),
|
||||||
headers := '{"Content-Type": "application/json"}'::jsonb
|
headers := '{"Content-Type": "application/json"}'::jsonb
|
||||||
)
|
);
|
||||||
as request_id;
|
|
||||||
$$;
|
$$;
|
||||||
|
|
|
@ -0,0 +1,40 @@
|
||||||
|
-- downloads data async into the http response table.
|
||||||
|
select
|
||||||
|
cron.schedule(
|
||||||
|
'download-bus-data',
|
||||||
|
'5 seconds',
|
||||||
|
$$
|
||||||
|
select gather_bus_data();
|
||||||
|
$$
|
||||||
|
);
|
||||||
|
|
||||||
|
-- copies data into a more permanent tabe/more useful format. note:
|
||||||
|
-- supabase has an issue where you cannot delete these triggers
|
||||||
|
-- directly, but a cascading delete of the trigger function also
|
||||||
|
-- removes the trigger itself.
|
||||||
|
CREATE FUNCTION copy_to_raw_table() RETURNS trigger LANGUAGE plpgsql AS $$
|
||||||
|
BEGIN
|
||||||
|
-- NOTE: the http_response sequence resets on DB restart, so there
|
||||||
|
-- is potential for old responses to have duplicated ids. we use a
|
||||||
|
-- constraint to only update newer entries (within the last 30
|
||||||
|
-- seconds). this should make accidentally overwriting older data
|
||||||
|
-- with newer values difficult. The API also provides a
|
||||||
|
-- lastUpdated value. we require that raw.created is at or after
|
||||||
|
-- that value to be updated.
|
||||||
|
update raw_bus_positions raw
|
||||||
|
set response_json = NEW.content::jsonb,
|
||||||
|
response_status = NEW.status_code
|
||||||
|
where raw.request_id = NEW.id
|
||||||
|
-- fairly generous constraint to account for long requests.
|
||||||
|
and raw.created >= (NEW.created - '30 seconds'::interval)
|
||||||
|
and raw.created >= (NEW.content::jsonb->'data'->'BusLocationByRoute'->>'lastUpdate')::timestamptz
|
||||||
|
and raw.response_json is null;
|
||||||
|
RETURN NULL; -- this is an AFTER trigger
|
||||||
|
END;
|
||||||
|
$$;
|
||||||
|
|
||||||
|
CREATE CONSTRAINT TRIGGER copy_http_response
|
||||||
|
AFTER INSERT ON net._http_response
|
||||||
|
DEFERRABLE INITIALLY DEFERRED
|
||||||
|
FOR EACH ROW
|
||||||
|
EXECUTE FUNCTION copy_to_raw_table();
|
Loading…
Reference in New Issue