mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 13:07:08 +00:00
150 lines
4.0 KiB
PL/PgSQL
150 lines
4.0 KiB
PL/PgSQL
-- 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 all schemas in the database.
|
|
-- 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 <<EOF
|
|
-- \i $THIS_FILE
|
|
-- COMMIT;
|
|
-- EOF
|
|
--
|
|
-- NOTE: It can be applied multiple times without ill effect.
|
|
--
|
|
|
|
BEGIN;
|
|
|
|
CREATE OR REPLACE PROCEDURE pg_temp.show_notice (notice text) AS $$
|
|
BEGIN
|
|
RAISE NOTICE '%', notice;
|
|
END;
|
|
$$ LANGUAGE plpgsql;
|
|
|
|
CREATE OR REPLACE PROCEDURE pg_temp.upgrade_survey_schema (schema_name text) AS $outer$
|
|
BEGIN
|
|
|
|
RAISE NOTICE 'Updating schema %', schema_name;
|
|
-- We need to set the search path because some of the trigger
|
|
-- functions reference other tables in survey schemas assuming
|
|
-- they are in the search path.
|
|
EXECUTE format('SET search_path TO %I,public', schema_name);
|
|
|
|
CREATE OR REPLACE PROCEDURE augment_event_data (maxspan numeric)
|
|
LANGUAGE sql
|
|
AS $$
|
|
-- Populate the timestamp of sequence / point events
|
|
UPDATE event_log_full
|
|
SET tstamp = tstamp_from_sequence_shot(sequence, point)
|
|
WHERE
|
|
tstamp IS NULL AND sequence IS NOT NULL AND point IS NOT NULL;
|
|
|
|
-- Populate the geometry of sequence / point events for which
|
|
-- there is raw_shots data.
|
|
UPDATE event_log_full
|
|
SET meta = meta ||
|
|
jsonb_build_object(
|
|
'geometry',
|
|
(
|
|
SELECT st_transform(geometry, 4326)::jsonb
|
|
FROM raw_shots rs
|
|
WHERE rs.sequence = event_log_full.sequence AND rs.point = event_log_full.point
|
|
)
|
|
)
|
|
WHERE
|
|
sequence IS NOT NULL AND point IS NOT NULL AND
|
|
NOT meta ? 'geometry';
|
|
|
|
-- Populate the geometry of time-based events
|
|
UPDATE event_log_full e
|
|
SET
|
|
meta = meta || jsonb_build_object('geometry',
|
|
(SELECT st_transform(g.geometry, 4326)::jsonb
|
|
FROM interpolate_geometry_from_tstamp(e.tstamp, maxspan) g))
|
|
WHERE
|
|
tstamp IS NOT NULL AND
|
|
sequence IS NULL AND point IS NULL AND
|
|
NOT meta ? 'geometry';
|
|
|
|
-- Get rid of null geometries
|
|
UPDATE event_log_full
|
|
SET
|
|
meta = meta - 'geometry'
|
|
WHERE
|
|
jsonb_typeof(meta->'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
|
|
--
|