-- Fix not being able to edit a time-based event. -- -- New schema version: 0.3.4 -- -- 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 creates a new procedure augment_event_data() which tries to -- populate missing event_log data, namely timestamps and geometries. -- -- To do this it also adds a function public.geometry_from_tstamp() -- which, given a timestamp, tries to fetch a geometry from real_time_inputs. -- -- 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'; $inner$; COMMENT ON PROCEDURE augment_event_data() IS 'Populate missing timestamps and geometries in event_log_full'; END; $$ LANGUAGE plpgsql; CREATE OR REPLACE PROCEDURE pg_temp.upgrade_17 () AS $$ DECLARE row RECORD; BEGIN CALL show_notice('Adding index to real_time_inputs.meta->tstamp'); CREATE INDEX IF NOT EXISTS meta_tstamp_idx ON public.real_time_inputs USING btree ((meta->>'tstamp') DESC); CALL show_notice('Creating function geometry_from_tstamp'); CREATE OR REPLACE FUNCTION public.geometry_from_tstamp( IN ts timestamptz, IN tolerance numeric, OUT "geometry" geometry, OUT "delta" numeric) AS $inner$ SELECT geometry, extract('epoch' FROM (meta->>'tstamp')::timestamptz - ts ) AS delta FROM real_time_inputs WHERE geometry IS NOT NULL AND abs(extract('epoch' FROM (meta->>'tstamp')::timestamptz - ts )) < tolerance ORDER BY abs(extract('epoch' FROM (meta->>'tstamp')::timestamptz - ts )) LIMIT 1; $inner$ LANGUAGE SQL; COMMENT ON FUNCTION public.geometry_from_tstamp(timestamptz, numeric) IS 'Get geometry from timestamp'; 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_17(); CALL show_notice('Cleaning up'); DROP PROCEDURE pg_temp.upgrade_survey_schema (schema_name text); DROP PROCEDURE pg_temp.upgrade_17 (); CALL show_notice('Updating db_schema version'); INSERT INTO public.info VALUES ('version', '{"db_schema": "0.3.4"}') ON CONFLICT (key) DO UPDATE SET value = public.info.value || '{"db_schema": "0.3.4"}' 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 --