mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 10:07:08 +00:00
268 lines
7.4 KiB
MySQL
268 lines
7.4 KiB
MySQL
|
|
-- 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 <<EOF
|
||
|
|
-- \i $THIS_FILE
|
||
|
|
-- COMMIT;
|
||
|
|
-- EOF
|
||
|
|
--
|
||
|
|
-- NOTE: It can be applied multiple times without ill effect.
|
||
|
|
--
|
||
|
|
|
||
|
|
BEGIN;
|
||
|
|
|
||
|
|
CREATE OR REPLACE PROCEDURE 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);
|
||
|
|
|
||
|
|
--
|
||
|
|
-- event_position(): Fetch event position
|
||
|
|
--
|
||
|
|
|
||
|
|
CREATE OR REPLACE FUNCTION event_position (
|
||
|
|
tstamp timestamptz, sequence integer, point integer, tolerance numeric
|
||
|
|
)
|
||
|
|
RETURNS geometry
|
||
|
|
AS $$
|
||
|
|
DECLARE
|
||
|
|
position geometry;
|
||
|
|
BEGIN
|
||
|
|
|
||
|
|
-- Try and get position by sequence / point first
|
||
|
|
IF sequence IS NOT NULL AND point IS NOT NULL THEN
|
||
|
|
-- Try and get the position from final_shots or raw_shots
|
||
|
|
SELECT COALESCE(f.geometry, r.geometry) geometry
|
||
|
|
INTO position
|
||
|
|
FROM raw_shots r LEFT JOIN final_shots f USING (sequence, point)
|
||
|
|
WHERE r.sequence = event_position.sequence AND r.point = event_position.point;
|
||
|
|
|
||
|
|
IF position IS NOT NULL THEN
|
||
|
|
RETURN position;
|
||
|
|
ELSIF tstamp IS NULL THEN
|
||
|
|
-- Get the timestamp for the sequence / point, if we can.
|
||
|
|
-- It will be used later in the function as we fall back
|
||
|
|
-- to timestamp based search.
|
||
|
|
-- We also adjust the tolerance as we're now dealing with
|
||
|
|
-- an exact timestamp.
|
||
|
|
SELECT COALESCE(f.tstamp, r.tstamp) tstamp, 0.002 tolerance
|
||
|
|
INTO tstamp, tolerance
|
||
|
|
FROM raw_shots r LEFT JOIN final_shots f USING (sequence, point)
|
||
|
|
WHERE r.sequence = event_position.sequence AND r.point = event_position.point;
|
||
|
|
END IF;
|
||
|
|
END IF;
|
||
|
|
|
||
|
|
-- If we got here, we better have a timestamp
|
||
|
|
-- First attempt, get a position from final_shots, raw_shots. This may
|
||
|
|
-- be redundant if we got here from the position of having a sequence /
|
||
|
|
-- point without a position, but never mind.
|
||
|
|
SELECT COALESCE(f.geometry, r.geometry) geometry
|
||
|
|
INTO position
|
||
|
|
FROM raw_shots r LEFT JOIN final_shots f USING (sequence, point)
|
||
|
|
WHERE r.tstamp = event_position.tstamp OR f.tstamp = event_position.tstamp
|
||
|
|
LIMIT 1; -- Just to be sure
|
||
|
|
|
||
|
|
IF position IS NULL THEN
|
||
|
|
-- Ok, so everything else so far has failed, let's try and get this
|
||
|
|
-- from real time data. We skip the search via sequence / point and
|
||
|
|
-- go directly for timestamp.
|
||
|
|
SELECT geometry
|
||
|
|
INTO position
|
||
|
|
FROM geometry_from_tstamp(tstamp, tolerance);
|
||
|
|
END IF;
|
||
|
|
|
||
|
|
RETURN position;
|
||
|
|
|
||
|
|
END;
|
||
|
|
$$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
COMMENT ON FUNCTION event_position (timestamptz, integer, integer, numeric) IS
|
||
|
|
'Return the position 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 geometry.';
|
||
|
|
|
||
|
|
CREATE OR REPLACE FUNCTION event_position (
|
||
|
|
tstamp timestamptz, sequence integer, point integer
|
||
|
|
)
|
||
|
|
RETURNS geometry
|
||
|
|
AS $$
|
||
|
|
BEGIN
|
||
|
|
RETURN event_position(tstamp, sequence, point, 3);
|
||
|
|
END;
|
||
|
|
$$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
COMMENT ON FUNCTION event_position (timestamptz, integer, integer) IS
|
||
|
|
'Overload of event_position with a default tolerance of three seconds.';
|
||
|
|
|
||
|
|
|
||
|
|
CREATE OR REPLACE FUNCTION event_position (
|
||
|
|
tstamp timestamptz
|
||
|
|
)
|
||
|
|
RETURNS geometry
|
||
|
|
AS $$
|
||
|
|
BEGIN
|
||
|
|
RETURN event_position(tstamp, NULL, NULL);
|
||
|
|
END;
|
||
|
|
$$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
COMMENT ON FUNCTION event_position (timestamptz) IS
|
||
|
|
'Overload of event_position (timestamptz, integer, integer) for use when searching by timestamp.';
|
||
|
|
|
||
|
|
CREATE OR REPLACE FUNCTION event_position (
|
||
|
|
sequence integer, point integer
|
||
|
|
)
|
||
|
|
RETURNS geometry
|
||
|
|
AS $$
|
||
|
|
BEGIN
|
||
|
|
RETURN event_position(NULL, sequence, point);
|
||
|
|
END;
|
||
|
|
$$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
COMMENT ON FUNCTION event_position (integer, integer) IS
|
||
|
|
'Overload of event_position (timestamptz, integer, integer) for use when searching by sequence / point.';
|
||
|
|
|
||
|
|
|
||
|
|
END;
|
||
|
|
$outer$ LANGUAGE plpgsql;
|
||
|
|
|
||
|
|
CREATE OR REPLACE PROCEDURE pg_temp.upgrade () AS $outer$
|
||
|
|
DECLARE
|
||
|
|
row RECORD;
|
||
|
|
BEGIN
|
||
|
|
|
||
|
|
--
|
||
|
|
-- event_meta(): Fetch event metadata
|
||
|
|
--
|
||
|
|
|
||
|
|
CREATE OR REPLACE FUNCTION event_meta (
|
||
|
|
tstamp timestamptz, sequence integer, point integer
|
||
|
|
)
|
||
|
|
RETURNS jsonb
|
||
|
|
AS $$
|
||
|
|
DECLARE
|
||
|
|
result jsonb;
|
||
|
|
-- Tolerance is hard-coded, at least until a need to expose arises.
|
||
|
|
tolerance numeric;
|
||
|
|
BEGIN
|
||
|
|
tolerance := 3; -- seconds
|
||
|
|
|
||
|
|
-- We search by timestamp if we can, as that's a lot quicker
|
||
|
|
IF tstamp IS NOT NULL THEN
|
||
|
|
|
||
|
|
SELECT meta
|
||
|
|
INTO result
|
||
|
|
FROM real_time_inputs rti
|
||
|
|
WHERE
|
||
|
|
rti.tstamp BETWEEN (event_meta.tstamp - tolerance * interval '1 second') AND (event_meta.tstamp + tolerance * interval '1 second')
|
||
|
|
ORDER BY abs(extract('epoch' FROM rti.tstamp - event_meta.tstamp ))
|
||
|
|
LIMIT 1;
|
||
|
|
|
||
|
|
ELSE
|
||
|
|
|
||
|
|
SELECT meta
|
||
|
|
INTO result
|
||
|
|
FROM real_time_inputs rti
|
||
|
|
WHERE
|
||
|
|
(meta->>'_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
|
||
|
|
--
|