Update database templates to v0.3.8.

* Add event_position()
* Add event_meta()
This commit is contained in:
D. Berge
2022-05-12 21:40:23 +02:00
parent 732d8e9be6
commit 1da02738b0
3 changed files with 241 additions and 2 deletions

View File

@@ -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
--