diff --git a/etc/db/database-template.sql b/etc/db/database-template.sql index cf5bbb9..941f049 100644 --- a/etc/db/database-template.sql +++ b/etc/db/database-template.sql @@ -273,6 +273,78 @@ ALTER FUNCTION public.geometry_from_tstamp(ts timestamp with time zone, toleranc COMMENT ON FUNCTION public.geometry_from_tstamp(ts timestamp with time zone, tolerance numeric, OUT geometry public.geometry, OUT delta numeric) IS 'Get geometry from timestamp'; +-- +-- Name: interpolate_geometry_from_tstamp(timestamp with time zone, numeric); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.interpolate_geometry_from_tstamp(ts timestamp with time zone, maxspan numeric) RETURNS public.geometry + LANGUAGE plpgsql + 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; + $$; + + +ALTER FUNCTION public.interpolate_geometry_from_tstamp(ts timestamp with time zone, maxspan numeric) OWNER TO postgres; + +-- +-- Name: FUNCTION interpolate_geometry_from_tstamp(ts timestamp with time zone, maxspan numeric); Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON FUNCTION public.interpolate_geometry_from_tstamp(ts timestamp with time zone, maxspan numeric) IS 'Interpolate a position over a given maximum timespan (in seconds) + based on real-time inputs. Returns a POINT geometry.'; + + -- -- Name: notify(); Type: FUNCTION; Schema: public; Owner: postgres -- diff --git a/etc/db/database-version.sql b/etc/db/database-version.sql index cd5dbc2..e84f5e9 100644 --- a/etc/db/database-version.sql +++ b/etc/db/database-version.sql @@ -1,3 +1,3 @@ -INSERT INTO public.info VALUES ('version', '{"db_schema": "0.3.9"}') +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.9"}' WHERE public.info.key = 'version'; + SET value = public.info.value || '{"db_schema": "0.3.10"}' WHERE public.info.key = 'version';