Add database upgrade file 23.

This defines a interpolate_geometry_from_tstamp(), taking a timestamp
and a maximum timespan in seconds. It will then interpolate a position
at the exact timestamp based on data from real_time_inputs, provided
that the effective interpolation timespan does not exceed the maximum
requested.

Fixes #243.
This commit is contained in:
D. Berge
2022-05-12 21:51:00 +02:00
parent 1992efe914
commit 23de4d00d7

View File

@@ -0,0 +1,127 @@
-- Fix not being able to edit a time-based event.
--
-- New schema version: 0.3.10
--
-- ATTENTION:
--
-- ENSURE YOU HAVE BACKED UP THE DATABASE BEFORE RUNNING THIS SCRIPT.
--
--
-- NOTE: This upgrade affects only the public schema.
-- NOTE: Each application starts a transaction, which must be committed
-- or rolled back.
--
-- This defines a interpolate_geometry_from_tstamp(), taking a timestamp
-- and a maximum timespan in seconds. It will then interpolate a position
-- at the exact timestamp based on data from real_time_inputs, provided
-- that the effective interpolation timespan does not exceed the maximum
-- requested.
--
-- To apply, run as the dougal user:
--
-- psql <<EOF
-- \i $THIS_FILE
-- COMMIT;
-- EOF
--
-- NOTE: It can be applied multiple times without ill effect.
--
BEGIN;
CREATE OR REPLACE PROCEDURE pg_temp.show_notice (notice text) AS $$
BEGIN
RAISE NOTICE '%', notice;
END;
$$ LANGUAGE plpgsql;
CREATE OR REPLACE PROCEDURE pg_temp.upgrade () AS $outer$
BEGIN
CALL pg_temp.show_notice('Defining interpolate_geometry_from_tstamp()');
CREATE OR REPLACE FUNCTION public.interpolate_geometry_from_tstamp(
IN ts timestamptz,
IN maxspan numeric
)
RETURNS geometry
AS $$
DECLARE
ts0 timestamptz;
ts1 timestamptz;
geom0 geometry;
geom1 geometry;
span numeric;
fraction numeric;
BEGIN
SELECT tstamp, geometry
INTO ts0, geom0
FROM real_time_inputs
WHERE tstamp <= ts
ORDER BY tstamp DESC
LIMIT 1;
SELECT tstamp, geometry
INTO ts1, geom1
FROM real_time_inputs
WHERE tstamp >= ts
ORDER BY tstamp ASC
LIMIT 1;
IF geom0 IS NULL OR geom1 IS NULL THEN
RAISE NOTICE 'Interpolation failed (no straddling data)';
RETURN NULL;
END IF;
-- See if we got an exact match
IF ts0 = ts THEN
RETURN geom0;
ELSIF ts1 = ts THEN
RETURN geom1;
END IF;
span := extract('epoch' FROM ts1 - ts0);
IF span > maxspan THEN
RAISE NOTICE 'Interpolation timespan % outside maximum requested (%)', span, maxspan;
RETURN NULL;
END IF;
fraction := extract('epoch' FROM ts - ts0) / span;
IF fraction < 0 OR fraction > 1 THEN
RAISE NOTICE 'Requested timestamp % outside of interpolation span (fraction: %)', ts, fraction;
RETURN NULL;
END IF;
RETURN ST_LineInterpolatePoint(St_MakeLine(geom0, geom1), fraction);
END;
$$ LANGUAGE plpgsql;
COMMENT ON FUNCTION public.interpolate_geometry_from_tstamp(timestamptz, numeric) IS
'Interpolate a position over a given maximum timespan (in seconds)
based on real-time inputs. Returns a POINT geometry.';
END;
$outer$ LANGUAGE plpgsql;
CALL pg_temp.upgrade();
CALL pg_temp.show_notice('Cleaning up');
DROP PROCEDURE pg_temp.upgrade ();
CALL pg_temp.show_notice('Updating db_schema version');
INSERT INTO public.info VALUES ('version', '{"db_schema": "0.3.10"}')
ON CONFLICT (key) DO UPDATE
SET value = public.info.value || '{"db_schema": "0.3.10"}' WHERE public.info.key = 'version';
CALL pg_temp.show_notice('All done. You may now run "COMMIT;" to persist the changes');
DROP PROCEDURE pg_temp.show_notice (notice text);
--
--NOTE Run `COMMIT;` now if all went well
--