From 4b832babfda898f4db8297855d8de3b0c9e69c07 Mon Sep 17 00:00:00 2001 From: "D. Berge" Date: Fri, 13 May 2022 18:53:32 +0200 Subject: [PATCH] Add database upgrade file 25. This defines a midnight_shots view and a log_midnight_shots() procedure (with some overloads). The view returns all points straddling midnight UTC and belonging to the same sequence (so last shot of the day and first shot of the next day). The procedure inserts the corresponding events (optionally constrained by an earliest and a latest date) in the event log, unless the events already exist. Related to #223. --- ...5-v0.3.12-add-midnight-shots-procedure.sql | 177 ++++++++++++++++++ 1 file changed, 177 insertions(+) create mode 100644 etc/db/upgrades/upgrade25-v0.3.12-add-midnight-shots-procedure.sql diff --git a/etc/db/upgrades/upgrade25-v0.3.12-add-midnight-shots-procedure.sql b/etc/db/upgrades/upgrade25-v0.3.12-add-midnight-shots-procedure.sql new file mode 100644 index 0000000..90fd4d5 --- /dev/null +++ b/etc/db/upgrades/upgrade25-v0.3.12-add-midnight-shots-procedure.sql @@ -0,0 +1,177 @@ +-- Fix not being able to edit a time-based event. +-- +-- New schema version: 0.3.12 +-- +-- 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 midnight_shots view and a log_midnight_shots() procedure +-- (with some overloads). The view returns all points straddling midnight +-- UTC and belonging to the same sequence (so last shot of the day and +-- first shot of the next day). +-- +-- The procedure inserts the corresponding events (optionally constrained +-- by an earliest and a latest date) in the event log, unless the events +-- already exist. +-- +-- To apply, run as the dougal user: +-- +-- psql <= dt0) AND + (dt1 IS NULL OR ms.tstamp <= dt1) AND + NOT EXISTS ( + SELECT 1 + FROM event_log el + WHERE ms.sequence = el.sequence AND ms.point = el.point AND el.labels @> ms.labels + ); + $$; + + COMMENT ON PROCEDURE log_midnight_shots (date, date) + IS 'Add midnight shots between two dates dt0 and dt1 to the event_log, unless the events already exist.'; + + + CREATE OR REPLACE PROCEDURE log_midnight_shots (dt0 date) + LANGUAGE sql + AS $$ + CALL log_midnight_shots(dt0, NULL); + $$; + + COMMENT ON PROCEDURE log_midnight_shots (date) + IS 'Overload taking only a dt0 (adds events on that date or after).'; + + CREATE OR REPLACE PROCEDURE log_midnight_shots () + LANGUAGE sql + AS $$ + CALL log_midnight_shots(NULL, NULL); + $$; + + COMMENT ON PROCEDURE log_midnight_shots () + IS 'Overload taking no arguments (adds all missing events).'; + +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.12"}') +ON CONFLICT (key) DO UPDATE + SET value = public.info.value || '{"db_schema": "0.3.12"}' 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 +--