-- Fix not being able to edit a time-based event. -- -- New schema version: 0.3.9 -- -- ATTENTION: -- -- ENSURE YOU HAVE BACKED UP THE DATABASE BEFORE RUNNING THIS SCRIPT. -- -- -- NOTE: This upgrade affects all schemas in the database. -- NOTE: Each application starts a transaction, which must be committed -- or rolled back. -- -- This defines a replace_placeholders() function, taking as arguments -- a text string and either a timestamp or a sequence / point pair. It -- uses the latter arguments to find metadata from which it can extract -- relevant information and replace it into the text string wherever the -- appropriate placeholders appear. For instance, given a call such as -- replace_placeholders('The position is @POS@', NULL, 11, 2600) it will -- replace '@POS@' with the position of point 2600 in sequence 11, if it -- exists (or leave the placeholder untouched otherwise). -- -- A scan_placeholders() procedure is also defined, which calls the above -- function on the entire event log. -- -- To apply, run as the dougal user: -- -- psql <>'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; $$ LANGUAGE plpgsql; COMMENT ON FUNCTION replace_placeholders (text, timestamptz, integer, integer) IS 'Replace certain placeholder strings in the input text with data obtained from shot or real-time data.'; CREATE OR REPLACE PROCEDURE 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; $$; COMMENT ON PROCEDURE scan_placeholders () IS 'Run replace_placeholders() on the entire event log.'; END; $outer$ LANGUAGE plpgsql; CREATE OR REPLACE PROCEDURE pg_temp.upgrade () AS $outer$ DECLARE row RECORD; BEGIN FOR row IN SELECT schema_name FROM information_schema.schemata WHERE schema_name LIKE 'survey_%' ORDER BY schema_name LOOP CALL pg_temp.upgrade_survey_schema(row.schema_name); END LOOP; END; $outer$ LANGUAGE plpgsql; CALL pg_temp.upgrade(); CALL show_notice('Cleaning up'); DROP PROCEDURE pg_temp.upgrade_survey_schema (schema_name text); DROP PROCEDURE pg_temp.upgrade (); CALL show_notice('Updating db_schema version'); 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.9"}' WHERE public.info.key = 'version'; CALL show_notice('All done. You may now run "COMMIT;" to persist the changes'); DROP PROCEDURE show_notice (notice text); -- --NOTE Run `COMMIT;` now if all went well --