diff --git a/etc/db/database-template.sql b/etc/db/database-template.sql index 5e9c08f..cf5bbb9 100644 --- a/etc/db/database-template.sql +++ b/etc/db/database-template.sql @@ -144,6 +144,107 @@ CREATE TYPE public.queue_item_status AS ENUM ( ALTER TYPE public.queue_item_status OWNER TO postgres; +-- +-- Name: event_meta(timestamp with time zone); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.event_meta(tstamp timestamp with time zone) RETURNS jsonb + LANGUAGE plpgsql + AS $$ + BEGIN + RETURN event_meta(tstamp, NULL, NULL); + END; + $$; + + +ALTER FUNCTION public.event_meta(tstamp timestamp with time zone) OWNER TO postgres; + +-- +-- Name: FUNCTION event_meta(tstamp timestamp with time zone); Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON FUNCTION public.event_meta(tstamp timestamp with time zone) IS 'Overload of event_meta (timestamptz, integer, integer) for use when searching by timestamp.'; + + +-- +-- Name: event_meta(integer, integer); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.event_meta(sequence integer, point integer) RETURNS jsonb + LANGUAGE plpgsql + AS $$ + BEGIN + RETURN event_meta(NULL, sequence, point); + END; + $$; + + +ALTER FUNCTION public.event_meta(sequence integer, point integer) OWNER TO postgres; + +-- +-- Name: FUNCTION event_meta(sequence integer, point integer); Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON FUNCTION public.event_meta(sequence integer, point integer) IS 'Overload of event_meta (timestamptz, integer, integer) for use when searching by sequence / point.'; + + +-- +-- Name: event_meta(timestamp with time zone, integer, integer); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.event_meta(tstamp timestamp with time zone, sequence integer, point integer) RETURNS jsonb + LANGUAGE plpgsql + AS $$ + DECLARE + result jsonb; + -- Tolerance is hard-coded, at least until a need to expose arises. + tolerance numeric; + BEGIN + tolerance := 3; -- seconds + + -- We search by timestamp if we can, as that's a lot quicker + IF tstamp IS NOT NULL THEN + + SELECT meta + INTO result + FROM real_time_inputs rti + WHERE + rti.tstamp BETWEEN (event_meta.tstamp - tolerance * interval '1 second') AND (event_meta.tstamp + tolerance * interval '1 second') + ORDER BY abs(extract('epoch' FROM rti.tstamp - event_meta.tstamp )) + LIMIT 1; + + ELSE + + SELECT meta + INTO result + FROM real_time_inputs rti + WHERE + (meta->>'_sequence')::integer = event_meta.sequence AND + (meta->>'_point')::integer = event_meta.point + ORDER BY rti.tstamp DESC + LIMIT 1; + + END IF; + + RETURN result; + + END; + $$; + + +ALTER FUNCTION public.event_meta(tstamp timestamp with time zone, sequence integer, point integer) OWNER TO postgres; + +-- +-- Name: FUNCTION event_meta(tstamp timestamp with time zone, sequence integer, point integer); Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON FUNCTION public.event_meta(tstamp timestamp with time zone, sequence integer, point integer) IS 'Return the real-time event metadata associated with a sequence / point in the current project or + with a given timestamp. Timestamp that is first searched for in the shot tables + of the current prospect or, if not found, in the real-time data. + + Returns a JSONB object.'; + + -- -- Name: geometry_from_tstamp(timestamp with time zone, numeric); Type: FUNCTION; Schema: public; Owner: postgres -- diff --git a/etc/db/database-version.sql b/etc/db/database-version.sql index d259719..ca106dc 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.7"}') +INSERT INTO public.info VALUES ('version', '{"db_schema": "0.3.8"}') ON CONFLICT (key) DO UPDATE - SET value = public.info.value || '{"db_schema": "0.3.7"}' WHERE public.info.key = 'version'; + SET value = public.info.value || '{"db_schema": "0.3.8"}' WHERE public.info.key = 'version'; diff --git a/etc/db/schema-template.sql b/etc/db/schema-template.sql index 6be07a9..4a8c95b 100644 --- a/etc/db/schema-template.sql +++ b/etc/db/schema-template.sql @@ -496,6 +496,144 @@ CREATE FUNCTION _SURVEY__TEMPLATE_.event_log_update() RETURNS trigger ALTER FUNCTION _SURVEY__TEMPLATE_.event_log_update() OWNER TO postgres; +-- +-- Name: event_position(timestamp with time zone); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +CREATE FUNCTION _SURVEY__TEMPLATE_.event_position(tstamp timestamp with time zone) RETURNS public.geometry + LANGUAGE plpgsql + AS $$ + BEGIN + RETURN event_position(tstamp, NULL, NULL); + END; + $$; + + +ALTER FUNCTION _SURVEY__TEMPLATE_.event_position(tstamp timestamp with time zone) OWNER TO postgres; + +-- +-- Name: FUNCTION event_position(tstamp timestamp with time zone); Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +COMMENT ON FUNCTION _SURVEY__TEMPLATE_.event_position(tstamp timestamp with time zone) IS 'Overload of event_position (timestamptz, integer, integer) for use when searching by timestamp.'; + + +-- +-- Name: event_position(integer, integer); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +CREATE FUNCTION _SURVEY__TEMPLATE_.event_position(sequence integer, point integer) RETURNS public.geometry + LANGUAGE plpgsql + AS $$ + BEGIN + RETURN event_position(NULL, sequence, point); + END; + $$; + + +ALTER FUNCTION _SURVEY__TEMPLATE_.event_position(sequence integer, point integer) OWNER TO postgres; + +-- +-- Name: FUNCTION event_position(sequence integer, point integer); Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +COMMENT ON FUNCTION _SURVEY__TEMPLATE_.event_position(sequence integer, point integer) IS 'Overload of event_position (timestamptz, integer, integer) for use when searching by sequence / point.'; + + +-- +-- Name: event_position(timestamp with time zone, integer, integer); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +CREATE FUNCTION _SURVEY__TEMPLATE_.event_position(tstamp timestamp with time zone, sequence integer, point integer) RETURNS public.geometry + LANGUAGE plpgsql + AS $$ + BEGIN + RETURN event_position(tstamp, sequence, point, 3); + END; + $$; + + +ALTER FUNCTION _SURVEY__TEMPLATE_.event_position(tstamp timestamp with time zone, sequence integer, point integer) OWNER TO postgres; + +-- +-- Name: FUNCTION event_position(tstamp timestamp with time zone, sequence integer, point integer); Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +COMMENT ON FUNCTION _SURVEY__TEMPLATE_.event_position(tstamp timestamp with time zone, sequence integer, point integer) IS 'Overload of event_position with a default tolerance of three seconds.'; + + +-- +-- Name: event_position(timestamp with time zone, integer, integer, numeric); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +CREATE FUNCTION _SURVEY__TEMPLATE_.event_position(tstamp timestamp with time zone, sequence integer, point integer, tolerance numeric) RETURNS public.geometry + LANGUAGE plpgsql + AS $$ + DECLARE + position geometry; + BEGIN + + -- Try and get position by sequence / point first + IF sequence IS NOT NULL AND point IS NOT NULL THEN + -- Try and get the position from final_shots or raw_shots + SELECT COALESCE(f.geometry, r.geometry) geometry + INTO position + FROM raw_shots r LEFT JOIN final_shots f USING (sequence, point) + WHERE r.sequence = event_position.sequence AND r.point = event_position.point; + + IF position IS NOT NULL THEN + RETURN position; + ELSIF tstamp IS NULL THEN + -- Get the timestamp for the sequence / point, if we can. + -- It will be used later in the function as we fall back + -- to timestamp based search. + -- We also adjust the tolerance as we're now dealing with + -- an exact timestamp. + SELECT COALESCE(f.tstamp, r.tstamp) tstamp, 0.002 tolerance + INTO tstamp, tolerance + FROM raw_shots r LEFT JOIN final_shots f USING (sequence, point) + WHERE r.sequence = event_position.sequence AND r.point = event_position.point; + END IF; + END IF; + + -- If we got here, we better have a timestamp + -- First attempt, get a position from final_shots, raw_shots. This may + -- be redundant if we got here from the position of having a sequence / + -- point without a position, but never mind. + SELECT COALESCE(f.geometry, r.geometry) geometry + INTO position + FROM raw_shots r LEFT JOIN final_shots f USING (sequence, point) + WHERE r.tstamp = event_position.tstamp OR f.tstamp = event_position.tstamp + LIMIT 1; -- Just to be sure + + IF position IS NULL THEN + -- Ok, so everything else so far has failed, let's try and get this + -- from real time data. We skip the search via sequence / point and + -- go directly for timestamp. + SELECT geometry + INTO position + FROM geometry_from_tstamp(tstamp, tolerance); + END IF; + + RETURN position; + + END; + $$; + + +ALTER FUNCTION _SURVEY__TEMPLATE_.event_position(tstamp timestamp with time zone, sequence integer, point integer, tolerance numeric) OWNER TO postgres; + +-- +-- Name: FUNCTION event_position(tstamp timestamp with time zone, sequence integer, point integer, tolerance numeric); Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +COMMENT ON FUNCTION _SURVEY__TEMPLATE_.event_position(tstamp timestamp with time zone, sequence integer, point integer, tolerance numeric) IS 'Return the position associated with a sequence / point in the current project or + with a given timestamp. Timestamp that is first searched for in the shot tables + of the current prospect or, if not found, in the real-time data. + + Returns a geometry.'; + + -- -- Name: events_seq_labels_single(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres --