mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 10:17:07 +00:00
178 lines
4.8 KiB
MySQL
178 lines
4.8 KiB
MySQL
|
|
-- Fix not being able to edit a time-based event.
|
||
|
|
--
|
||
|
|
-- New schema version: 0.3.12
|
||
|
|
--
|
||
|
|
-- 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 defines a midnight_shots view and a log_midnight_shots() procedure
|
||
|
|
-- (with some overloads). The view returns all points straddling midnight
|
||
|
|
-- UTC and belonging to the same sequence (so last shot of the day and
|
||
|
|
-- first shot of the next day).
|
||
|
|
--
|
||
|
|
-- The procedure inserts the corresponding events (optionally constrained
|
||
|
|
-- by an earliest and a latest date) in the event log, unless the events
|
||
|
|
-- already exist.
|
||
|
|
--
|
||
|
|
-- 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 VIEW midnight_shots AS
|
||
|
|
WITH straddlers AS (
|
||
|
|
-- Get sequence numbers straddling midnight UTC
|
||
|
|
SELECT sequence
|
||
|
|
FROM raw_shots
|
||
|
|
GROUP BY sequence
|
||
|
|
HAVING min(date(tstamp)) != max(date(tstamp))
|
||
|
|
),
|
||
|
|
ts AS (
|
||
|
|
-- Get earliest and latest timestamps for each day
|
||
|
|
-- for each of the above sequences.
|
||
|
|
-- This will return the timestamps for:
|
||
|
|
-- FSP, LDSP, FDSP, LSP.
|
||
|
|
SELECT
|
||
|
|
rs.sequence,
|
||
|
|
min(rs.tstamp) AS ts0,
|
||
|
|
max(rs.tstamp) AS ts1
|
||
|
|
FROM raw_shots rs INNER JOIN straddlers USING (sequence)
|
||
|
|
GROUP BY rs.sequence, (date(rs.tstamp))
|
||
|
|
ORDER BY rs.sequence, date(rs.tstamp)
|
||
|
|
),
|
||
|
|
spts AS (
|
||
|
|
-- Filter out FSP, LSP from the above.
|
||
|
|
-- NOTE: This *should* in theory be able to cope with
|
||
|
|
-- a sequence longer than 24 hours (so with more than
|
||
|
|
-- one LDSP, FDSP) but that hasn't been tested.
|
||
|
|
SELECT DISTINCT
|
||
|
|
sequence,
|
||
|
|
min(ts1) OVER (PARTITION BY sequence) ldsp,
|
||
|
|
max(ts0) OVER (PARTITION BY sequence) fdsp
|
||
|
|
FROM ts
|
||
|
|
ORDER BY sequence
|
||
|
|
), evt AS (
|
||
|
|
SELECT
|
||
|
|
rs.tstamp,
|
||
|
|
rs.sequence,
|
||
|
|
point,
|
||
|
|
'Last shotpoint of the day' remarks,
|
||
|
|
'{LDSP}'::text[] labels
|
||
|
|
FROM raw_shots rs
|
||
|
|
INNER JOIN spts ON rs.sequence = spts.sequence AND rs.tstamp = spts.ldsp
|
||
|
|
UNION SELECT
|
||
|
|
rs.tstamp,
|
||
|
|
rs.sequence,
|
||
|
|
point,
|
||
|
|
'First shotpoint of the day' remarks,
|
||
|
|
'{FDSP}'::text[] labels
|
||
|
|
FROM raw_shots rs
|
||
|
|
INNER JOIN spts ON rs.sequence = spts.sequence AND rs.tstamp = spts.fdsp
|
||
|
|
ORDER BY tstamp
|
||
|
|
)
|
||
|
|
SELECT * FROM evt;
|
||
|
|
|
||
|
|
|
||
|
|
CREATE OR REPLACE PROCEDURE log_midnight_shots (dt0 date, dt1 date)
|
||
|
|
LANGUAGE sql
|
||
|
|
AS $$
|
||
|
|
INSERT INTO event_log (sequence, point, remarks, labels)
|
||
|
|
SELECT sequence, point, remarks, labels
|
||
|
|
FROM midnight_shots ms
|
||
|
|
WHERE
|
||
|
|
(dt0 IS NULL OR ms.tstamp >= dt0) AND
|
||
|
|
(dt1 IS NULL OR ms.tstamp <= dt1) AND
|
||
|
|
NOT EXISTS (
|
||
|
|
SELECT 1
|
||
|
|
FROM event_log el
|
||
|
|
WHERE ms.sequence = el.sequence AND ms.point = el.point AND el.labels @> ms.labels
|
||
|
|
);
|
||
|
|
$$;
|
||
|
|
|
||
|
|
COMMENT ON PROCEDURE log_midnight_shots (date, date)
|
||
|
|
IS 'Add midnight shots between two dates dt0 and dt1 to the event_log, unless the events already exist.';
|
||
|
|
|
||
|
|
|
||
|
|
CREATE OR REPLACE PROCEDURE log_midnight_shots (dt0 date)
|
||
|
|
LANGUAGE sql
|
||
|
|
AS $$
|
||
|
|
CALL log_midnight_shots(dt0, NULL);
|
||
|
|
$$;
|
||
|
|
|
||
|
|
COMMENT ON PROCEDURE log_midnight_shots (date)
|
||
|
|
IS 'Overload taking only a dt0 (adds events on that date or after).';
|
||
|
|
|
||
|
|
CREATE OR REPLACE PROCEDURE log_midnight_shots ()
|
||
|
|
LANGUAGE sql
|
||
|
|
AS $$
|
||
|
|
CALL log_midnight_shots(NULL, NULL);
|
||
|
|
$$;
|
||
|
|
|
||
|
|
COMMENT ON PROCEDURE log_midnight_shots ()
|
||
|
|
IS 'Overload taking no arguments (adds all missing events).';
|
||
|
|
|
||
|
|
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.12"}')
|
||
|
|
ON CONFLICT (key) DO UPDATE
|
||
|
|
SET value = public.info.value || '{"db_schema": "0.3.12"}' 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
|
||
|
|
--
|