-- Fix not being able to edit a time-based event. -- -- New schema version: 0.3.8 -- -- 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 adds event_position() and event_meta() functions which are used -- to retrieve position or metadata, respectively, given either a timestamp -- or a sequence / point pair. Intended to be used in the context of #229. -- -- To apply, run as the dougal user: -- -- psql <>'_sequence')::integer = event_meta.sequence AND (meta->>'_point')::integer = event_meta.point ORDER BY rti.tstamp DESC LIMIT 1; END IF; RETURN result; END; $$ LANGUAGE plpgsql; COMMENT ON FUNCTION event_meta (timestamptz, integer, integer) IS 'Return the real-time event metadata associated with a sequence / point in the current project or with a given timestamp. Timestamp that is first searched for in the shot tables of the current prospect or, if not found, in the real-time data. Returns a JSONB object.'; CREATE OR REPLACE FUNCTION event_meta ( tstamp timestamptz ) RETURNS jsonb AS $$ BEGIN RETURN event_meta(tstamp, NULL, NULL); END; $$ LANGUAGE plpgsql; COMMENT ON FUNCTION event_meta (timestamptz) IS 'Overload of event_meta (timestamptz, integer, integer) for use when searching by timestamp.'; CREATE OR REPLACE FUNCTION event_meta ( sequence integer, point integer ) RETURNS jsonb AS $$ BEGIN RETURN event_meta(NULL, sequence, point); END; $$ LANGUAGE plpgsql; COMMENT ON FUNCTION event_meta (integer, integer) IS 'Overload of event_meta (timestamptz, integer, integer) for use when searching by sequence / point.'; 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.8"}') ON CONFLICT (key) DO UPDATE SET value = public.info.value || '{"db_schema": "0.3.8"}' 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 --