jokull/supabase/migrations/20240409190001_bus_funcs.sql

68 lines
2.2 KiB
MySQL
Raw Normal View History

2024-04-09 21:05:05 +00:00
-- extensions
CREATE EXTENSION IF NOT EXISTS "plv8" SCHEMA pg_catalog;
CREATE EXTENSION IF NOT EXISTS "pg_cron" SCHEMA pg_catalog;
CREATE EXTENSION IF NOT EXISTS "pg_net" SCHEMA extensions;
-- request ID is inserted by first cron job,
-- then second cron job updates from net._http_response table.
create table if not exists raw_bus_positions (
2024-04-09 22:03:44 +00:00
id BIGINT GENERATED ALWAYS AS IDENTITY,
request_id INT not null,
created TIMESTAMP WITH TIME ZONE not null default now(),
response_status INT null,
response_json JSONB null
2024-04-09 21:05:05 +00:00
);
-- used to help craft the API URL. Requires plv8 extension.
-- because we are lazy. just use javascript in the database. why not?
create or replace function to_straeto_querystring(jsonb) returns text
language plv8 strict immutable as $$
const obj = $1;
return Object.keys(obj).map(function(variableName) {
const variableValue = obj[variableName];
if (typeof variableValue == 'object') {
return encodeURIComponent(variableName) + '=' + encodeURIComponent(JSON.stringify(variableValue));
} else {
return encodeURIComponent(variableName) + '=' + encodeURIComponent(variableValue);
}
}).join('&');
$$;
create or replace function create_straeto_parameters(bus_routes text[]) returns jsonb
language plpgsql as $$
declare query_params jsonb;
begin
query_params := '{
"operationName": "BusLocationByRoute",
"variables": { "trips":[], "routes": [] },
"extensions": {
"persistedQuery": {
"version": 1,
"sha256Hash": "8f9ee84171961f8a3b9a9d1a7b2a7ac49e7e122e1ba1727e75cfe3a94ff3edb8"
}
}
}'::jsonb;
select into query_params
jsonb_set(query_params, '{variables, routes}', array_to_json(bus_routes)::jsonb);
return query_params;
end
$$;
create or replace function create_api_url(bus_routes text[]) returns text language sql as $$
select concat(
'https://straeto.is/graphql?',
to_straeto_querystring(create_straeto_parameters(bus_routes))
);
$$;
create or replace function gather_bus_data()
returns void language sql
2024-04-09 21:05:05 +00:00
as $$
insert into raw_bus_positions (request_id) select
2024-04-09 21:05:05 +00:00
net.http_get(
url := create_api_url(array['1', '2', '3']),
headers := '{"Content-Type": "application/json"}'::jsonb
);
2024-04-09 21:05:05 +00:00
$$;