diff --git a/etc/db/database-version.sql b/etc/db/database-version.sql index ca106dc..cd5dbc2 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.8"}') +INSERT INTO public.info VALUES ('version', '{"db_schema": "0.3.9"}') ON CONFLICT (key) DO UPDATE - SET value = public.info.value || '{"db_schema": "0.3.8"}' WHERE public.info.key = 'version'; + SET value = public.info.value || '{"db_schema": "0.3.9"}' WHERE public.info.key = 'version'; diff --git a/etc/db/schema-template.sql b/etc/db/schema-template.sql index 4a8c95b..832e161 100644 --- a/etc/db/schema-template.sql +++ b/etc/db/schema-template.sql @@ -936,6 +936,166 @@ CREATE FUNCTION _SURVEY__TEMPLATE_.label_in_sequence(_sequence integer, _label t ALTER FUNCTION _SURVEY__TEMPLATE_.label_in_sequence(_sequence integer, _label text) OWNER TO postgres; +-- +-- Name: replace_placeholders(text, timestamp with time zone, integer, integer); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +CREATE FUNCTION _SURVEY__TEMPLATE_.replace_placeholders(text_in text, tstamp timestamp with time zone, sequence integer, point integer) RETURNS text + LANGUAGE plpgsql + AS $_$ + DECLARE + position geometry; + metadata jsonb; + text_out text; + + json_query text; + json_result jsonb; + expect_recursion boolean := false; + BEGIN + + text_out := text_in; + + -- We only get a position if we are going to need it… + IF regexp_match(text_out, '@DMS@|@POS@|@DEG@') IS NOT NULL THEN + position := ST_Transform(event_position(tstamp, sequence, point), 4326); + END IF; + + -- …and likewise with the metadata. + IF regexp_match(text_out, '@BSP@|@WD@|@CMG@|@EN@|@GRID@|@(\$\..*?)@@') IS NOT NULL THEN + metadata := event_meta(tstamp, sequence, point); + END IF; + + -- We shortcut the evaluation if neither of the above regexps matched + IF position IS NULL AND metadata IS NULL THEN + RETURN text_out; + END IF; + + IF position('@DMS@' IN text_out) != 0 THEN + text_out := replace(text_out, '@DMS@', ST_AsLatLonText(position)); + END IF; + + IF position('@POS@' IN text_out) != 0 THEN + text_out := replace(text_out, '@POS@', replace(ST_AsLatLonText(position, 'D.DDDDDD'), ' ', ', ')); + END IF; + + IF position('@DEG@' IN text_out) != 0 THEN + text_out := replace(text_out, '@DEG@', replace(ST_AsLatLonText(position, 'D.DDDDDD'), ' ', ', ')); + END IF; + + IF position('@EN@' IN text_out) != 0 THEN + IF metadata ? 'easting' AND metadata ? 'northing' THEN + text_out := replace(text_out, '@EN@', (metadata->>'easting') || ', ' || (metadata->>'northing')); + END IF; + END IF; + + IF position('@GRID@' IN text_out) != 0 THEN + IF metadata ? 'easting' AND metadata ? 'northing' THEN + text_out := replace(text_out, '@GRID@', (metadata->>'easting') || ', ' || (metadata->>'northing')); + END IF; + END IF; + + IF position('@CMG@' IN text_out) != 0 THEN + IF metadata ? 'bearing' THEN + text_out := replace(text_out, '@CMG@', metadata->>'bearing'); + END IF; + END IF; + + IF position('@BSP@' IN text_out) != 0 THEN + IF metadata ? 'speed' THEN + text_out := replace(text_out, '@BSP@', round((metadata->>'speed')::numeric * 3600 / 1852, 1)::text); + END IF; + END IF; + + IF position('@WD@' IN text_out) != 0 THEN + IF metadata ? 'waterDepth' THEN + text_out := replace(text_out, '@WD@', metadata->>'waterDepth'); + END IF; + END IF; + + json_query := (regexp_match(text_out, '@(\$\..*?)@@'))[1]; + IF json_query IS NOT NULL THEN + json_result := jsonb_path_query_array(metadata, json_query::jsonpath); + IF jsonb_array_length(json_result) = 1 THEN + text_out := replace(text_out, '@'||json_query||'@@', json_result->>0); + ELSE + text_out := replace(text_out, '@'||json_query||'@@', json_result::text); + END IF; + -- There might be multiple JSONPath queries, so we may have to recurse + expect_recursion := true; + END IF; + + IF expect_recursion IS TRUE AND text_in != text_out THEN + --RAISE NOTICE 'Recursing %', text_out; + -- We don't know if we have found all the JSONPath expression + -- so we do another pass. + RETURN replace_placeholders(text_out, tstamp, sequence, point); + ELSE + RETURN text_out; + END IF; + + END; + $_$; + + +ALTER FUNCTION _SURVEY__TEMPLATE_.replace_placeholders(text_in text, tstamp timestamp with time zone, sequence integer, point integer) OWNER TO postgres; + +-- +-- Name: FUNCTION replace_placeholders(text_in text, tstamp timestamp with time zone, sequence integer, point integer); Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +COMMENT ON FUNCTION _SURVEY__TEMPLATE_.replace_placeholders(text_in text, tstamp timestamp with time zone, sequence integer, point integer) IS 'Replace certain placeholder strings in the input text with data obtained from shot or real-time data.'; + + +-- +-- Name: scan_placeholders(); Type: PROCEDURE; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +CREATE PROCEDURE _SURVEY__TEMPLATE_.scan_placeholders() + LANGUAGE sql + AS $_$ + -- We update non read-only events via the event_log view to leave a trace + -- of the fact that placeholders were replaced (and when). + -- Note that this will not replace placeholders of old edits. + UPDATE event_log + SET remarks = replace_placeholders(remarks, tstamp, sequence, point) + FROM ( + SELECT id + FROM event_log e + WHERE + (meta->'readonly')::boolean IS NOT TRUE AND ( + regexp_match(remarks, '@DMS@|@POS@|@DEG@') IS NOT NULL OR + regexp_match(remarks, '@BSP@|@WD@|@CMG@|@EN@|@GRID@|@(\$\..*?)@@') IS NOT NULL + ) + ) t + WHERE event_log.id = t.id; + + -- And then we update read-only events directly on the event_log_full table + -- (as of this version of the schema we're prevented from updating read-only + -- events via event_log anyway). + UPDATE event_log_full + SET remarks = replace_placeholders(remarks, tstamp, sequence, point) + FROM ( + SELECT uid + FROM event_log_full e + WHERE + (meta->'readonly')::boolean IS TRUE AND ( + regexp_match(remarks, '@DMS@|@POS@|@DEG@') IS NOT NULL OR + regexp_match(remarks, '@BSP@|@WD@|@CMG@|@EN@|@GRID@|@(\$\..*?)@@') IS NOT NULL + ) + ) t + WHERE event_log_full.uid = t.uid; + $_$; + + +ALTER PROCEDURE _SURVEY__TEMPLATE_.scan_placeholders() OWNER TO postgres; + +-- +-- Name: PROCEDURE scan_placeholders(); Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +COMMENT ON PROCEDURE _SURVEY__TEMPLATE_.scan_placeholders() IS 'Run replace_placeholders() on the entire event log.'; + + -- -- Name: to_binning_grid(public.geometry); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres --