From 53bb75a2c1d761ff593124ad2494e19aee8c7f48 Mon Sep 17 00:00:00 2001 From: "D. Berge" Date: Mon, 7 Mar 2022 21:02:25 +0100 Subject: [PATCH] Add new database upgrade file 11. Some of the things in new upgrade file 12 depend on the functions defined here. --- .../upgrade11-v0.2.1-tstamp-functions.sql | 137 ++++++++++++++++++ 1 file changed, 137 insertions(+) create mode 100644 etc/db/upgrades/upgrade11-v0.2.1-tstamp-functions.sql diff --git a/etc/db/upgrades/upgrade11-v0.2.1-tstamp-functions.sql b/etc/db/upgrades/upgrade11-v0.2.1-tstamp-functions.sql new file mode 100644 index 0000000..cee0bd4 --- /dev/null +++ b/etc/db/upgrades/upgrade11-v0.2.1-tstamp-functions.sql @@ -0,0 +1,137 @@ +-- Add function to retrieve sequence/shotpoint from timestamps and vice-versa +-- +-- New schema version: 0.2.1 +-- +-- ATTENTION: +-- +-- ENSURE YOU HAVE BACKED UP THE DATABASE BEFORE RUNNING THIS SCRIPT. +-- +-- +-- NOTE: This upgrade affects the public schema. +-- NOTE: Each application starts a transaction, which must be committed +-- or rolled back. +-- +-- Two new functions are defined: +-- +-- sequence_shot_from_tstamp(tstamp, [tolerance]) → sequence, point, delta +-- +-- Returns a sequence + shotpoint if one falls within `tolerance` seconds +-- of `tstamp`. The tolerance may be omitted in which case it defaults to +-- three seconds. If multiple values match, it returns the closest in time. +-- +-- tstamp_from_sequence_shot(sequence, point) → tstamp +-- +-- Returns a timestamp given a sequence and point number. +-- +-- NOTE: This last function must be called from a search path including a +-- project schema, as it accesses the raw_shots table. +-- +-- To apply, run as the dougal user: +-- +-- psql <>'_sequence')::numeric AS sequence, + (meta->>'_point')::numeric AS point, + extract('epoch' FROM (meta->>'tstamp')::timestamptz - ts ) AS delta + FROM real_time_inputs + WHERE + meta ? '_sequence' AND + abs(extract('epoch' FROM (meta->>'tstamp')::timestamptz - ts )) < tolerance + ORDER BY abs(extract('epoch' FROM (meta->>'tstamp')::timestamptz - ts )) + LIMIT 1; + $inner$ LANGUAGE SQL; + + + CREATE OR REPLACE FUNCTION public.sequence_shot_from_tstamp( + IN ts timestamptz, + OUT "sequence" numeric, + OUT "point" numeric, + OUT "delta" numeric) + AS $inner$ + SELECT * FROM public.sequence_shot_from_tstamp(ts, 3); + $inner$ LANGUAGE SQL; + + + FOR row IN + SELECT schema_name FROM information_schema.schemata + WHERE schema_name LIKE 'survey_%' + ORDER BY schema_name + LOOP + CALL pg_temp.upgrade_survey_schema(row.schema_name); + END LOOP; + +END; +$$ LANGUAGE plpgsql; + +CALL pg_temp.upgrade_database(); + +CALL show_notice('Cleaning up'); +DROP PROCEDURE pg_temp.upgrade_survey_schema (schema_name text); +DROP PROCEDURE pg_temp.upgrade_database (); + +CALL show_notice('Updating db_schema version'); + + +INSERT INTO public.info VALUES ('version', '{"db_schema": "0.2.1"}') +ON CONFLICT (key) DO UPDATE + SET value = public.info.value || '{"db_schema": "0.2.1"}' WHERE public.info.key = 'version'; + + +-- +--NOTE Run `COMMIT;` now if all went well +--