2022-03-07 21:02:25 +01:00
|
|
|
-- 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 <<EOF
|
|
|
|
|
-- \i $THIS_FILE
|
|
|
|
|
-- COMMIT;
|
|
|
|
|
-- EOF
|
|
|
|
|
--
|
|
|
|
|
-- NOTE: It can take a while if run on a large database.
|
|
|
|
|
-- NOTE: It can be applied multiple times without ill effect.
|
|
|
|
|
-- NOTE: This will lock the database while the transaction is active.
|
|
|
|
|
--
|
|
|
|
|
-- WARNING: Applying this upgrade drops the old tables. Ensure that you
|
|
|
|
|
-- have migrated the data first.
|
|
|
|
|
--
|
|
|
|
|
-- NOTE: This is a patch version change so it does not require a
|
|
|
|
|
-- backend restart.
|
|
|
|
|
|
|
|
|
|
BEGIN;
|
|
|
|
|
|
|
|
|
|
CREATE OR REPLACE PROCEDURE show_notice (notice text) AS $$
|
|
|
|
|
BEGIN
|
|
|
|
|
RAISE NOTICE '%', notice;
|
|
|
|
|
END;
|
|
|
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
|
|
|
|
|
|
CREATE OR REPLACE PROCEDURE pg_temp.upgrade_survey_schema (schema_name text) AS $$
|
|
|
|
|
BEGIN
|
|
|
|
|
|
|
|
|
|
RAISE NOTICE 'Updating schema %', schema_name;
|
|
|
|
|
-- We need to set the search path because some of the trigger
|
|
|
|
|
-- functions reference other tables in survey schemas assuming
|
|
|
|
|
-- they are in the search path.
|
|
|
|
|
EXECUTE format('SET search_path TO %I,public', schema_name);
|
|
|
|
|
|
|
|
|
|
CREATE OR REPLACE FUNCTION tstamp_from_sequence_shot(
|
|
|
|
|
IN s numeric,
|
|
|
|
|
IN p numeric,
|
|
|
|
|
OUT "ts" timestamptz)
|
|
|
|
|
AS $inner$
|
|
|
|
|
SELECT tstamp FROM raw_shots WHERE sequence = s AND point = p LIMIT 1;
|
|
|
|
|
$inner$ LANGUAGE SQL;
|
|
|
|
|
|
2022-03-09 21:21:01 +01:00
|
|
|
|
|
|
|
|
COMMENT ON FUNCTION tstamp_from_sequence_shot(numeric, numeric)
|
|
|
|
|
IS 'Get the timestamp of an existing shotpoint.';
|
|
|
|
|
|
|
|
|
|
|
2022-03-09 21:21:48 +01:00
|
|
|
CREATE OR REPLACE FUNCTION tstamp_interpolate(s numeric, p numeric) RETURNS timestamptz
|
|
|
|
|
AS $inner$
|
|
|
|
|
DECLARE
|
|
|
|
|
ts0 timestamptz;
|
|
|
|
|
ts1 timestamptz;
|
|
|
|
|
pt0 numeric;
|
|
|
|
|
pt1 numeric;
|
|
|
|
|
BEGIN
|
|
|
|
|
|
|
|
|
|
SELECT tstamp, point
|
|
|
|
|
INTO ts0, pt0
|
|
|
|
|
FROM raw_shots
|
|
|
|
|
WHERE sequence = s AND point < p
|
|
|
|
|
ORDER BY point DESC LIMIT 1;
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
SELECT tstamp, point
|
|
|
|
|
INTO ts1, pt1
|
|
|
|
|
FROM raw_shots
|
|
|
|
|
WHERE sequence = s AND point > p
|
|
|
|
|
ORDER BY point ASC LIMIT 1;
|
|
|
|
|
|
|
|
|
|
RETURN (ts1-ts0)/abs(pt1-pt0)*abs(p-pt0)+ts0;
|
|
|
|
|
|
|
|
|
|
END;
|
|
|
|
|
$inner$ LANGUAGE PLPGSQL;
|
|
|
|
|
|
|
|
|
|
COMMENT ON FUNCTION tstamp_interpolate(numeric, numeric)
|
|
|
|
|
IS 'Interpolate a timestamp given sequence and point values.
|
|
|
|
|
|
|
|
|
|
It will try to find the points immediately before and after in the sequence and interpolate into the gap, which may consist of multiple missed shots.
|
|
|
|
|
|
|
|
|
|
If called on an existing shotpoint it will return an interpolated timestamp as if the shotpoint did not exist, as opposed to returning its actual timestamp.
|
|
|
|
|
|
|
|
|
|
Returns NULL if it is not possible to interpolate.';
|
2022-03-09 21:21:01 +01:00
|
|
|
|
2022-03-07 21:02:25 +01:00
|
|
|
END;
|
|
|
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
|
|
|
|
|
|
CREATE OR REPLACE PROCEDURE pg_temp.upgrade_database () AS $$
|
|
|
|
|
DECLARE
|
|
|
|
|
row RECORD;
|
|
|
|
|
BEGIN
|
|
|
|
|
|
|
|
|
|
|
|
|
|
|
CREATE OR REPLACE FUNCTION public.sequence_shot_from_tstamp(
|
|
|
|
|
IN ts timestamptz,
|
|
|
|
|
IN tolerance numeric,
|
|
|
|
|
OUT "sequence" numeric,
|
|
|
|
|
OUT "point" numeric,
|
|
|
|
|
OUT "delta" numeric)
|
|
|
|
|
AS $inner$
|
|
|
|
|
SELECT
|
|
|
|
|
(meta->>'_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;
|
|
|
|
|
|
|
|
|
|
|
2022-03-09 21:21:01 +01:00
|
|
|
COMMENT ON FUNCTION public.sequence_shot_from_tstamp(timestamptz, numeric)
|
|
|
|
|
IS 'Get sequence and shotpoint from timestamp.
|
|
|
|
|
|
|
|
|
|
Given a timestamp this function returns the closest shot to it within the given tolerance value.
|
|
|
|
|
|
|
|
|
|
This uses the `real_time_inputs` table and it does not give an indication of which project the shotpoint belongs to. It is assumed that a single project is being acquired at a given time.';
|
|
|
|
|
|
2022-03-07 21:02:25 +01:00
|
|
|
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;
|
|
|
|
|
|
2022-03-09 21:21:01 +01:00
|
|
|
COMMENT ON FUNCTION public.sequence_shot_from_tstamp(timestamptz)
|
|
|
|
|
IS 'Get sequence and shotpoint from timestamp.
|
|
|
|
|
|
|
|
|
|
Overloaded form in which the tolerance value is implied and defaults to three seconds.';
|
2022-03-07 21:02:25 +01:00
|
|
|
|
|
|
|
|
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
|
|
|
|
|
--
|