-- Fix not being able to edit a time-based event. -- -- New schema version: 0.3.3 -- -- 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. -- -- The event_log_update() function that gets called when trying to update -- the event_log view will not work if the caller does provide a timestamp -- or sequence + point in the list of fields to be updated. See: -- https://gitlab.com/wgp/dougal/software/-/issues/198 -- -- This fixes the problem by liberally using COALESCE() to merge the OLD -- and NEW records. -- -- To apply, run as the dougal user: -- -- psql <>'readonly')::boolean IS TRUE) THEN RAISE check_violation USING MESSAGE = 'Cannot modify read-only entry'; RETURN NULL; END IF; -- If the sequence / point has changed, and no new tstamp is provided, get one IF NEW.sequence <> OLD.sequence OR NEW.point <> OLD.point AND NEW.sequence IS NOT NULL AND NEW.point IS NOT NULL AND NEW.tstamp IS NULL OR NEW.tstamp = OLD.tstamp THEN SELECT COALESCE( tstamp_from_sequence_shot(NEW.sequence, NEW.point), tstamp_interpolate(NEW.sequence, NEW.point) ) INTO NEW.tstamp; END IF; UPDATE event_log_full SET validity = tstzrange(lower(validity), current_timestamp) WHERE validity @> current_timestamp AND id = OLD.id; -- Any attempt to modify id will be ignored. INSERT INTO event_log_full (id, tstamp, sequence, point, remarks, labels, meta) VALUES ( OLD.id, COALESCE(NEW.tstamp, OLD.tstamp), COALESCE(NEW.sequence, OLD.sequence), COALESCE(NEW.point, OLD.point), COALESCE(NEW.remarks, OLD.remarks), COALESCE(NEW.labels, OLD.labels), COALESCE(NEW.meta, OLD.meta) ); RETURN NEW; ELSIF (TG_OP = 'DELETE') THEN -- Set end of validity. -- NOTE: We *do* allow deleting an event that has meta.readonly = true -- This could be of interest if for instance we wanted to keep the history -- of QC results for a point, provided that the QC routines write to -- event_log and not event_log_full UPDATE event_log_full SET validity = tstzrange(lower(validity), current_timestamp) WHERE validity @> current_timestamp AND id = OLD.id; RETURN NULL; END IF; END; $inner$; CREATE OR REPLACE TRIGGER event_log_tg INSTEAD OF INSERT OR DELETE OR UPDATE ON event_log FOR EACH ROW EXECUTE FUNCTION event_log_update(); END; $$ LANGUAGE plpgsql; CREATE OR REPLACE PROCEDURE pg_temp.upgrade_16 () AS $$ 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; $$ LANGUAGE plpgsql; CALL pg_temp.upgrade_16(); CALL show_notice('Cleaning up'); DROP PROCEDURE pg_temp.upgrade_survey_schema (schema_name text); DROP PROCEDURE pg_temp.upgrade_16 (); CALL show_notice('Updating db_schema version'); INSERT INTO public.info VALUES ('version', '{"db_schema": "0.3.3"}') ON CONFLICT (key) DO UPDATE SET value = public.info.value || '{"db_schema": "0.3.3"}' 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 --