Merge branch '57-make-event-log-entries-for-start-and-end-of-line-upon-import-of-final-sequence-if-the-entries-do' into 'devel'

Resolve "Make event log entries for start and end of line upon import of final sequence, if the entries do not already exist"

Closes #57

See merge request wgp/dougal/software!11
This commit is contained in:
D. Berge
2021-05-24 15:44:58 +00:00
5 changed files with 403 additions and 71 deletions

View File

@@ -479,6 +479,8 @@ class Datastore:
if filedata is not None:
self.save_file_data(filepath, json.dumps(filedata), cursor)
cursor.execute("CALL final_line_post_import(%s);", (fileinfo["sequence"],))
self.maybe_commit()

View File

@@ -2,8 +2,8 @@
-- PostgreSQL database dump
--
-- Dumped from database version 12.4
-- Dumped by pg_dump version 12.4
-- Dumped from database version 12.6
-- Dumped by pg_dump version 12.7
SET statement_timeout = 0;
SET lock_timeout = 0;
@@ -136,6 +136,38 @@ $$;
ALTER FUNCTION _SURVEY__TEMPLATE_.clear_shot_qc() OWNER TO postgres;
--
-- Name: events_seq_labels_single(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE FUNCTION _SURVEY__TEMPLATE_.events_seq_labels_single() RETURNS trigger
LANGUAGE plpgsql
AS $$
DECLARE _sequence integer;
BEGIN
IF EXISTS(SELECT 1 FROM labels WHERE name = NEW.label AND (data->'model'->'multiple')::boolean IS FALSE) THEN
SELECT sequence INTO _sequence FROM events WHERE id = NEW.id;
DELETE
FROM events_seq_labels
WHERE
id <> NEW.id
AND label = NEW.label
AND id IN (SELECT id FROM events_seq WHERE sequence = _sequence);
DELETE
FROM events_timed_labels
WHERE
id <> NEW.id
AND label = NEW.label
AND id IN (SELECT id FROM events_timed_seq WHERE sequence = _sequence);
END IF;
RETURN NULL;
END;
$$;
ALTER FUNCTION _SURVEY__TEMPLATE_.events_seq_labels_single() OWNER TO postgres;
--
-- Name: events_timed_seq_match(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
@@ -213,82 +245,102 @@ $$;
ALTER PROCEDURE _SURVEY__TEMPLATE_.events_timed_seq_update_all() OWNER TO postgres;
--
-- Name: reset_events_serials(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
-- Name: final_line_post_import(integer); Type: PROCEDURE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE FUNCTION _SURVEY__TEMPLATE_.reset_events_serials() RETURNS void
CREATE PROCEDURE _SURVEY__TEMPLATE_.final_line_post_import(_seq integer)
LANGUAGE plpgsql
AS $$
BEGIN
PERFORM setval('events_timed_id_seq', (SELECT max(id)+1 FROM events_timed));
PERFORM setval('events_seq_id_seq', (SELECT max(id)+1 FROM events_seq));
CALL handle_final_line_events(_seq, 'FSP', 'fsp');
CALL handle_final_line_events(_seq, 'FGSP', 'fsp');
CALL handle_final_line_events(_seq, 'LGSP', 'lsp');
CALL handle_final_line_events(_seq, 'LSP', 'lsp');
END;
$$;
ALTER FUNCTION _SURVEY__TEMPLATE_.reset_events_serials() OWNER TO postgres;
ALTER PROCEDURE _SURVEY__TEMPLATE_.final_line_post_import(_seq integer) OWNER TO postgres;
--
-- Name: to_binning_grid(public.geometry); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
-- Name: handle_final_line_events(integer, text, text); Type: PROCEDURE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE FUNCTION _SURVEY__TEMPLATE_.to_binning_grid(geom public.geometry) RETURNS public.geometry
LANGUAGE plpgsql STABLE LEAKPROOF
AS $$DECLARE
bp jsonb := binning_parameters();
theta numeric := (bp->>'theta')::numeric * pi() / 180;
I_inc numeric DEFAULT 1;
J_inc numeric DEFAULT 1;
I_width numeric := (bp->>'I_width')::numeric;
J_width numeric := (bp->>'J_width')::numeric;
CREATE PROCEDURE _SURVEY__TEMPLATE_.handle_final_line_events(_seq integer, _label text, _column text)
LANGUAGE plpgsql
AS $$
a numeric := (I_inc/I_width) * cos(theta);
b numeric := (I_inc/I_width) * -sin(theta);
c numeric := (J_inc/J_width) * sin(theta);
d numeric := (J_inc/J_width) * cos(theta);
xoff numeric := (bp->'origin'->>'I')::numeric;
yoff numeric := (bp->'origin'->>'J')::numeric;
E0 numeric := (bp->'origin'->>'easting')::numeric;
N0 numeric := (bp->'origin'->>'northing')::numeric;
DECLARE
_line final_lines_summary%ROWTYPE;
_column_value integer;
_tg_name text := 'final_line';
_event events%ROWTYPE;
event_id integer;
BEGIN
-- RAISE NOTICE 'Matrix: a: %, b: %, c: %, d: %, xoff: %, yoff: %', a, b, c, d, xoff, yoff;
RETURN ST_SetSRID(ST_Affine(ST_Translate(geom, -E0, -N0), a, b, c, d, xoff, yoff), 0);
END
SELECT * INTO _line FROM final_lines_summary WHERE sequence = _seq;
_event := label_in_sequence(_seq, _label);
_column_value := row_to_json(_line)->>_column;
--RAISE NOTICE '% is %', _label, _event;
--RAISE NOTICE 'Line is %', _line;
--RAISE NOTICE '% is % (%)', _column, _column_value, _label;
IF _event IS NULL THEN
--RAISE NOTICE 'We will populate the event log from the sequence data';
SELECT id INTO event_id FROM events_seq WHERE sequence = _seq AND point = _column_value ORDER BY id LIMIT 1;
IF event_id IS NULL THEN
--RAISE NOTICE ' but there is no existing event so we create a new one for sequence % and point %', _line.sequence, _column_value;
INSERT INTO events_seq (sequence, point, remarks)
VALUES (_line.sequence, _column_value, format('%s %s', _label, (SELECT meta->>'lineName' FROM final_lines WHERE sequence = _seq)))
RETURNING id INTO event_id;
--RAISE NOTICE 'Created event_id %', event_id;
END IF;
--RAISE NOTICE 'Remove any other auto-inserted % labels in sequence %', _label, _seq;
DELETE FROM events_seq_labels
WHERE label = _label AND id = (SELECT id FROM events_seq WHERE sequence = _seq AND meta->'auto' ? _label);
--RAISE NOTICE 'We now add a label to the event (id, label) = (%, %)', event_id, _label;
INSERT INTO events_seq_labels (id, label) VALUES (event_id, _label) ON CONFLICT ON CONSTRAINT events_seq_labels_pkey DO NOTHING;
--RAISE NOTICE 'And also clear the %: % flag from meta.auto for any existing events for sequence %', _label, _tg_name, _seq;
UPDATE events_seq
SET meta = meta #- ARRAY['auto', _label]
WHERE meta->'auto' ? _label AND sequence = _seq AND id <> event_id;
--RAISE NOTICE 'Finally, flag the event as having been had label % auto-created by %', _label, _tg_name;
UPDATE events_seq
SET meta = jsonb_set(jsonb_set(meta, '{auto}', COALESCE(meta->'auto', '{}')), ARRAY['auto', _label], to_jsonb(_tg_name))
WHERE id = event_id;
ELSE
--RAISE NOTICE 'We may populate the sequence meta from the event log';
--RAISE NOTICE 'Unless the event log was populated by us previously';
--RAISE NOTICE 'Populated by us previously? %', _event.meta->'auto'->>_label = _tg_name;
IF _event.meta->'auto'->>_label IS DISTINCT FROM _tg_name THEN
--RAISE NOTICE 'Adding % found in events log to final_line meta', _label;
UPDATE final_lines
SET meta = jsonb_set(meta, ARRAY[_label], to_jsonb(_event.point))
WHERE sequence = _seq;
--RAISE NOTICE 'Clearing the %: % flag from meta.auto for any existing events in sequence %', _label, _tg_name, _seq;
UPDATE events_seq
SET meta = meta #- ARRAY['auto', _label]
WHERE sequence = _seq AND meta->'auto'->>_label = _tg_name;
END IF;
END IF;
END;
$$;
ALTER FUNCTION _SURVEY__TEMPLATE_.to_binning_grid(geom public.geometry) OWNER TO postgres;
--
-- Name: to_binning_grid(public.geometry, jsonb); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE FUNCTION _SURVEY__TEMPLATE_.to_binning_grid(geom public.geometry, bp jsonb) RETURNS public.geometry
LANGUAGE plpgsql IMMUTABLE PARALLEL SAFE
AS $$DECLARE
-- bp jsonb := binning_parameters();
theta numeric := (bp->>'theta')::numeric * pi() / 180;
I_inc numeric DEFAULT 1;
J_inc numeric DEFAULT 1;
I_width numeric := (bp->>'I_width')::numeric;
J_width numeric := (bp->>'J_width')::numeric;
a numeric := (I_inc/I_width) * cos(theta);
b numeric := (I_inc/I_width) * -sin(theta);
c numeric := (J_inc/J_width) * sin(theta);
d numeric := (J_inc/J_width) * cos(theta);
xoff numeric := (bp->'origin'->>'I')::numeric;
yoff numeric := (bp->'origin'->>'J')::numeric;
E0 numeric := (bp->'origin'->>'easting')::numeric;
N0 numeric := (bp->'origin'->>'northing')::numeric;
BEGIN
-- RAISE NOTICE 'Matrix: a: %, b: %, c: %, d: %, xoff: %, yoff: %', a, b, c, d, xoff, yoff;
RETURN ST_SetSRID(ST_Affine(ST_Translate(geom, -E0, -N0), a, b, c, d, xoff, yoff), 0);
END
$$;
ALTER FUNCTION _SURVEY__TEMPLATE_.to_binning_grid(geom public.geometry, bp jsonb) OWNER TO postgres;
ALTER PROCEDURE _SURVEY__TEMPLATE_.handle_final_line_events(_seq integer, _label text, _column text) OWNER TO postgres;
SET default_tablespace = '';
@@ -561,7 +613,7 @@ UNION
v1.objref,
v1.tstamp,
v1.hash,
'{}'::jsonb meta,
'{}'::jsonb AS meta,
(public.st_asgeojson(public.st_transform(v1.geometry, 4326)))::jsonb AS geometry,
ARRAY[v1.label] AS labels
FROM _SURVEY__TEMPLATE_.events_midnight_shot v1
@@ -576,7 +628,7 @@ UNION
rs.objref,
rs.tstamp,
rs.hash,
'{}'::jsonb meta,
'{}'::jsonb AS meta,
(public.st_asgeojson(public.st_transform(rs.geometry, 4326)))::jsonb AS geometry,
('{QC}'::text[] || qc.labels) AS labels
FROM (_SURVEY__TEMPLATE_.raw_shots rs
@@ -587,6 +639,97 @@ UNION
ALTER TABLE _SURVEY__TEMPLATE_.events OWNER TO postgres;
--
-- Name: label_in_sequence(integer, text); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE FUNCTION _SURVEY__TEMPLATE_.label_in_sequence(_sequence integer, _label text) RETURNS _SURVEY__TEMPLATE_.events
LANGUAGE sql
AS $$
SELECT * FROM events WHERE sequence = _sequence AND _label = ANY(labels);
$$;
ALTER FUNCTION _SURVEY__TEMPLATE_.label_in_sequence(_sequence integer, _label text) OWNER TO postgres;
--
-- Name: reset_events_serials(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE FUNCTION _SURVEY__TEMPLATE_.reset_events_serials() RETURNS void
LANGUAGE plpgsql
AS $$
BEGIN
PERFORM setval('events_timed_id_seq', (SELECT max(id)+1 FROM events_timed));
PERFORM setval('events_seq_id_seq', (SELECT max(id)+1 FROM events_seq));
END;
$$;
ALTER FUNCTION _SURVEY__TEMPLATE_.reset_events_serials() OWNER TO postgres;
--
-- Name: to_binning_grid(public.geometry); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE FUNCTION _SURVEY__TEMPLATE_.to_binning_grid(geom public.geometry) RETURNS public.geometry
LANGUAGE plpgsql STABLE LEAKPROOF
AS $$DECLARE
bp jsonb := binning_parameters();
theta numeric := (bp->>'theta')::numeric * pi() / 180;
I_inc numeric DEFAULT 1;
J_inc numeric DEFAULT 1;
I_width numeric := (bp->>'I_width')::numeric;
J_width numeric := (bp->>'J_width')::numeric;
a numeric := (I_inc/I_width) * cos(theta);
b numeric := (I_inc/I_width) * -sin(theta);
c numeric := (J_inc/J_width) * sin(theta);
d numeric := (J_inc/J_width) * cos(theta);
xoff numeric := (bp->'origin'->>'I')::numeric;
yoff numeric := (bp->'origin'->>'J')::numeric;
E0 numeric := (bp->'origin'->>'easting')::numeric;
N0 numeric := (bp->'origin'->>'northing')::numeric;
BEGIN
-- RAISE NOTICE 'Matrix: a: %, b: %, c: %, d: %, xoff: %, yoff: %', a, b, c, d, xoff, yoff;
RETURN ST_SetSRID(ST_Affine(ST_Translate(geom, -E0, -N0), a, b, c, d, xoff, yoff), 0);
END
$$;
ALTER FUNCTION _SURVEY__TEMPLATE_.to_binning_grid(geom public.geometry) OWNER TO postgres;
--
-- Name: to_binning_grid(public.geometry, jsonb); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE FUNCTION _SURVEY__TEMPLATE_.to_binning_grid(geom public.geometry, bp jsonb) RETURNS public.geometry
LANGUAGE plpgsql IMMUTABLE PARALLEL SAFE
AS $$DECLARE
-- bp jsonb := binning_parameters();
theta numeric := (bp->>'theta')::numeric * pi() / 180;
I_inc numeric DEFAULT 1;
J_inc numeric DEFAULT 1;
I_width numeric := (bp->>'I_width')::numeric;
J_width numeric := (bp->>'J_width')::numeric;
a numeric := (I_inc/I_width) * cos(theta);
b numeric := (I_inc/I_width) * -sin(theta);
c numeric := (J_inc/J_width) * sin(theta);
d numeric := (J_inc/J_width) * cos(theta);
xoff numeric := (bp->'origin'->>'I')::numeric;
yoff numeric := (bp->'origin'->>'J')::numeric;
E0 numeric := (bp->'origin'->>'easting')::numeric;
N0 numeric := (bp->'origin'->>'northing')::numeric;
BEGIN
-- RAISE NOTICE 'Matrix: a: %, b: %, c: %, d: %, xoff: %, yoff: %', a, b, c, d, xoff, yoff;
RETURN ST_SetSRID(ST_Affine(ST_Translate(geom, -E0, -N0), a, b, c, d, xoff, yoff), 0);
END
$$;
ALTER FUNCTION _SURVEY__TEMPLATE_.to_binning_grid(geom public.geometry, bp jsonb) OWNER TO postgres;
--
-- Name: events_labels; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
@@ -1561,14 +1704,6 @@ ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_seq ALTER COLUMN id SET DEFAULT nextv
ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_timed ALTER COLUMN id SET DEFAULT nextval('_SURVEY__TEMPLATE_.events_timed_id_seq'::regclass);
--
-- Name: events_seq events_seq_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_seq
ADD CONSTRAINT events_seq_pkey PRIMARY KEY (id);
--
-- Name: events_seq_labels events_seq_labels_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
@@ -1577,6 +1712,14 @@ ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_seq_labels
ADD CONSTRAINT events_seq_labels_pkey PRIMARY KEY (id, label);
--
-- Name: events_seq events_seq_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_seq
ADD CONSTRAINT events_seq_pkey PRIMARY KEY (id);
--
-- Name: events_timed_labels events_timed_labels_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
@@ -1727,6 +1870,20 @@ CREATE INDEX events_seq_sequence_idx ON _SURVEY__TEMPLATE_.events_seq USING btre
CREATE INDEX events_timed_ts0_idx ON _SURVEY__TEMPLATE_.events_timed USING btree (tstamp);
--
-- Name: events_seq_labels events_seq_labels_single_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TRIGGER events_seq_labels_single_tg AFTER INSERT OR UPDATE ON _SURVEY__TEMPLATE_.events_seq_labels FOR EACH ROW EXECUTE FUNCTION _SURVEY__TEMPLATE_.events_seq_labels_single();
--
-- Name: events_timed_labels events_seq_labels_single_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TRIGGER events_timed_labels_single_tg AFTER INSERT OR UPDATE ON _SURVEY__TEMPLATE_.events_timed_labels FOR EACH ROW EXECUTE FUNCTION _SURVEY__TEMPLATE_.events_seq_labels_single();
--
-- Name: events_seq events_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--

View File

@@ -0,0 +1,171 @@
-- Upgrade the database from commit 53f71f70 to 4d977848.
--
-- NOTE: This upgrade must be applied to every schema in the database.
-- NOTE: Each application starts a transaction, which must be committed
-- or rolled back.
--
-- This adds:
--
-- * label_in_sequence (_sequence integer, _label text):
-- Returns events containing the specified label.
--
-- * handle_final_line_events (_seq integer, _label text, _column text):
-- - If _label does not exist in the events for sequence _seq:
-- it adds a new _label label at the shotpoint obtained from
-- final_lines_summary[_column].
-- - If _label does exist (and hasn't been auto-added by this function
-- in a previous run), it will add information about it to the final
-- line's metadata.
--
-- * final_line_post_import (_seq integer):
-- Calls handle_final_line_events() on the given sequence to check
-- for FSP, FGSP, LGSP and LSP labels.
--
-- * events_seq_labels_single ():
-- Trigger function to ensure that labels that have the attribute
-- `model.multiple` set to `false` occur at most only once per
-- sequence. If a new instance is added to a sequence, the previous
-- instance is deleted.
--
-- * Trigger on events_seq_labels that calls events_seq_labels_single().
--
-- * Trigger on events_timed_labels that calls events_seq_labels_single().
--
-- To apply, run as the dougal user, for every schema in the database:
--
-- psql <<EOF
-- SET search_path TO survey_*,public;
-- \i $THIS_FILE
-- COMMIT;
-- EOF
--
-- NOTE: It will fail harmlessly if applied twice.
BEGIN;
CREATE OR REPLACE FUNCTION label_in_sequence (_sequence integer, _label text)
RETURNS events
LANGUAGE sql
AS $$
SELECT * FROM events WHERE sequence = _sequence AND _label = ANY(labels);
$$;
CREATE OR REPLACE PROCEDURE handle_final_line_events (_seq integer, _label text, _column text)
LANGUAGE plpgsql
AS $$
DECLARE
_line final_lines_summary%ROWTYPE;
_column_value integer;
_tg_name text := 'final_line';
_event events%ROWTYPE;
event_id integer;
BEGIN
SELECT * INTO _line FROM final_lines_summary WHERE sequence = _seq;
_event := label_in_sequence(_seq, _label);
_column_value := row_to_json(_line)->>_column;
--RAISE NOTICE '% is %', _label, _event;
--RAISE NOTICE 'Line is %', _line;
--RAISE NOTICE '% is % (%)', _column, _column_value, _label;
IF _event IS NULL THEN
--RAISE NOTICE 'We will populate the event log from the sequence data';
SELECT id INTO event_id FROM events_seq WHERE sequence = _seq AND point = _column_value ORDER BY id LIMIT 1;
IF event_id IS NULL THEN
--RAISE NOTICE '… but there is no existing event so we create a new one for sequence % and point %', _line.sequence, _column_value;
INSERT INTO events_seq (sequence, point, remarks)
VALUES (_line.sequence, _column_value, format('%s %s', _label, (SELECT meta->>'lineName' FROM final_lines WHERE sequence = _seq)))
RETURNING id INTO event_id;
--RAISE NOTICE 'Created event_id %', event_id;
END IF;
--RAISE NOTICE 'Remove any other auto-inserted % labels in sequence %', _label, _seq;
DELETE FROM events_seq_labels
WHERE label = _label AND id = (SELECT id FROM events_seq WHERE sequence = _seq AND meta->'auto' ? _label);
--RAISE NOTICE 'We now add a label to the event (id, label) = (%, %)', event_id, _label;
INSERT INTO events_seq_labels (id, label) VALUES (event_id, _label) ON CONFLICT ON CONSTRAINT events_seq_labels_pkey DO NOTHING;
--RAISE NOTICE 'And also clear the %: % flag from meta.auto for any existing events for sequence %', _label, _tg_name, _seq;
UPDATE events_seq
SET meta = meta #- ARRAY['auto', _label]
WHERE meta->'auto' ? _label AND sequence = _seq AND id <> event_id;
--RAISE NOTICE 'Finally, flag the event as having been had label % auto-created by %', _label, _tg_name;
UPDATE events_seq
SET meta = jsonb_set(jsonb_set(meta, '{auto}', COALESCE(meta->'auto', '{}')), ARRAY['auto', _label], to_jsonb(_tg_name))
WHERE id = event_id;
ELSE
--RAISE NOTICE 'We may populate the sequence meta from the event log';
--RAISE NOTICE 'Unless the event log was populated by us previously';
--RAISE NOTICE 'Populated by us previously? %', _event.meta->'auto'->>_label = _tg_name;
IF _event.meta->'auto'->>_label IS DISTINCT FROM _tg_name THEN
--RAISE NOTICE 'Adding % found in events log to final_line meta', _label;
UPDATE final_lines
SET meta = jsonb_set(meta, ARRAY[_label], to_jsonb(_event.point))
WHERE sequence = _seq;
--RAISE NOTICE 'Clearing the %: % flag from meta.auto for any existing events in sequence %', _label, _tg_name, _seq;
UPDATE events_seq
SET meta = meta #- ARRAY['auto', _label]
WHERE sequence = _seq AND meta->'auto'->>_label = _tg_name;
END IF;
END IF;
END;
$$;
CREATE OR REPLACE PROCEDURE final_line_post_import (_seq integer)
LANGUAGE plpgsql
AS $$
BEGIN
CALL handle_final_line_events(_seq, 'FSP', 'fsp');
CALL handle_final_line_events(_seq, 'FGSP', 'fsp');
CALL handle_final_line_events(_seq, 'LGSP', 'lsp');
CALL handle_final_line_events(_seq, 'LSP', 'lsp');
END;
$$;
CREATE OR REPLACE FUNCTION events_seq_labels_single ()
RETURNS trigger
LANGUAGE plpgsql
AS $$
DECLARE _sequence integer;
BEGIN
IF EXISTS(SELECT 1 FROM labels WHERE name = NEW.label AND (data->'model'->'multiple')::boolean IS FALSE) THEN
SELECT sequence INTO _sequence FROM events WHERE id = NEW.id;
DELETE
FROM events_seq_labels
WHERE
id <> NEW.id
AND label = NEW.label
AND id IN (SELECT id FROM events_seq WHERE sequence = _sequence);
DELETE
FROM events_timed_labels
WHERE
id <> NEW.id
AND label = NEW.label
AND id IN (SELECT id FROM events_timed_seq WHERE sequence = _sequence);
END IF;
RETURN NULL;
END;
$$;
CREATE TRIGGER events_seq_labels_single_tg AFTER INSERT OR UPDATE ON events_seq_labels FOR EACH ROW EXECUTE FUNCTION events_seq_labels_single();
CREATE TRIGGER events_seq_labels_single_tg AFTER INSERT OR UPDATE ON events_timed_labels FOR EACH ROW EXECUTE FUNCTION events_seq_labels_single();
--
--NOTE Run `COMMIT;` now if all went well
--

View File

@@ -31,6 +31,7 @@ async function insertSequenceEventLabels(event, client) {
FROM unnest($2::text[]) l (name)
INNER JOIN labels USING (name)
WHERE (data->'model'->'user')::boolean IS true
ON CONFLICT ON CONSTRAINT events_seq_labels_pkey DO NOTHING;
`;
// console.log("insertSequenceEventLabels", text, event);

View File

@@ -51,7 +51,8 @@ async function updateSeqEventLabels (event, client) {
const text = `
INSERT INTO events_seq_labels (id, label)
SELECT $1, label FROM unnest($2::text[]) t (label);
SELECT $1, label FROM unnest($2::text[]) t (label)
ON CONFLICT ON CONSTRAINT events_seq_labels_pkey DO NOTHING;
`;
return client.query(text, [event.id, event.labels]);