From 7cea79a9be871028b42a0898574deb3524d01bbc Mon Sep 17 00:00:00 2001 From: "D. Berge" Date: Thu, 12 May 2022 21:57:23 +0200 Subject: [PATCH] Add database upgrade file 24. This redefines augment_event_data() to use interpolation rather than nearest neighbour. It now takes an argument indicating the maximum allowed interpolation timespan. An overload with a default of ten minutes is also provided, as an in situ replacement for the previous version. The ten minute default is based on Triggerfish headers behaviour seen on crew 248 during soft starts. --- ...v0.3.11-replace-augment-data-procedure.sql | 149 ++++++++++++++++++ 1 file changed, 149 insertions(+) create mode 100644 etc/db/upgrades/upgrade24-v0.3.11-replace-augment-data-procedure.sql diff --git a/etc/db/upgrades/upgrade24-v0.3.11-replace-augment-data-procedure.sql b/etc/db/upgrades/upgrade24-v0.3.11-replace-augment-data-procedure.sql new file mode 100644 index 0000000..f9316b7 --- /dev/null +++ b/etc/db/upgrades/upgrade24-v0.3.11-replace-augment-data-procedure.sql @@ -0,0 +1,149 @@ +-- Fix not being able to edit a time-based event. +-- +-- New schema version: 0.3.11 +-- +-- ATTENTION: +-- +-- ENSURE YOU HAVE BACKED UP THE DATABASE BEFORE RUNNING THIS SCRIPT. +-- +-- +-- NOTE: This upgrade affects only the public schema. +-- NOTE: Each application starts a transaction, which must be committed +-- or rolled back. +-- +-- This redefines augment_event_data() to use interpolation rather than +-- nearest neighbour. It now takes an argument indicating the maximum +-- allowed interpolation timespan. An overload with a default of ten +-- minutes is also provided, as an in situ replacement for the previous +-- version. +-- +-- The ten minute default is based on Triggerfish headers behaviour seen +-- on crew 248 during soft starts. +-- +-- To apply, run as the dougal user: +-- +-- psql <'geometry') = 'null'; + + -- Simplify the GeoJSON when the CRS is EPSG:4326 + UPDATE event_log_full + SET + meta = meta #- '{geometry, crs}' + WHERE + meta->'geometry'->'crs'->'properties'->>'name' = 'EPSG:4326'; + + $$; + + COMMENT ON PROCEDURE augment_event_data(numeric) + IS 'Populate missing timestamps and geometries in event_log_full'; + + CREATE OR REPLACE PROCEDURE augment_event_data () + LANGUAGE sql + AS $$ + CALL augment_event_data(600); + $$; + + COMMENT ON PROCEDURE augment_event_data() + IS 'Overload of augment_event_data(maxspan numeric) with a maxspan value of 600 seconds.'; + +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 pg_temp.show_notice('Cleaning up'); +DROP PROCEDURE pg_temp.upgrade_survey_schema (schema_name text); +DROP PROCEDURE pg_temp.upgrade (); + +CALL pg_temp.show_notice('Updating db_schema version'); +INSERT INTO public.info VALUES ('version', '{"db_schema": "0.3.11"}') +ON CONFLICT (key) DO UPDATE + SET value = public.info.value || '{"db_schema": "0.3.11"}' WHERE public.info.key = 'version'; + + +CALL pg_temp.show_notice('All done. You may now run "COMMIT;" to persist the changes'); +DROP PROCEDURE pg_temp.show_notice (notice text); + +-- +--NOTE Run `COMMIT;` now if all went well +--