Speed up the events view.

We do this with the help of some denormalisation
and a handy trigger.

Closes #35.
This commit is contained in:
D. Berge
2020-09-14 03:01:55 +02:00
parent b5b91d41c9
commit c9b9a009af
2 changed files with 107 additions and 46 deletions

View File

@@ -48,5 +48,8 @@ if __name__ == '__main__':
db.conn.commit() db.conn.commit()
# Update the sequences that generate event ids # Update the sequences that generate event ids
cur.execute("SELECT reset_events_serials();") cur.execute("SELECT reset_events_serials();")
# Let us ensure events_timed_seq is up to date, even though
# the triggers will have taken care of this already.
cur.execute("CALL events_timed_seq_update_all();")
print("Done") print("Done")

View File

@@ -433,51 +433,107 @@ CREATE VIEW _SURVEY__TEMPLATE_.raw_lines_summary AS
ALTER TABLE _SURVEY__TEMPLATE_.raw_lines_summary OWNER TO postgres; ALTER TABLE _SURVEY__TEMPLATE_.raw_lines_summary OWNER TO postgres;
-- --
-- Name: events_timed_seq; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- Name: events_timed_seq; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
-- --
CREATE VIEW _SURVEY__TEMPLATE_.events_timed_seq AS CREATE TABLE _SURVEY__TEMPLATE_.events_timed_seq (
WITH seqs AS ( id integer NOT NULL,
SELECT e.id, sequence integer NOT NULL,
e.remarks, point integer NOT NULL
e.tstamp, );
rls.sequence,
rls.fsp,
rls.lsp,
rls.ts0,
rls.ts1
FROM (_SURVEY__TEMPLATE_.events_timed e
LEFT JOIN _SURVEY__TEMPLATE_.raw_lines_summary rls ON (((e.tstamp >= rls.ts0) AND (e.tstamp <= rls.ts1))))
)
SELECT seqs.sequence,
seqs.id,
seqs.remarks,
seqs.tstamp,
seqs.fsp,
seqs.lsp,
seqs.ts0,
seqs.ts1,
shots.line,
shots.point,
shots.objref,
shots.tstamp AS shot_tstamp,
shots.hash,
shots.geometry
FROM (seqs
LEFT JOIN LATERAL ( SELECT rs.sequence,
rs.line,
rs.point,
rs.objref,
rs.tstamp,
rs.hash,
rs.geometry
FROM _SURVEY__TEMPLATE_.raw_shots rs
ORDER BY (seqs.tstamp OPERATOR(public.<->) rs.tstamp)
LIMIT 1) shots USING (sequence));
ALTER TABLE _SURVEY__TEMPLATE_.events_timed_seq OWNER TO postgres; ALTER TABLE _SURVEY__TEMPLATE_.events_timed_seq OWNER TO postgres;
--
-- Name: TABLE events_timed_seq; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON TABLE _SURVEY__TEMPLATE_.events_timed_seq IS 'If a timed event is within a sequence, this references the point shot at or just before the event time. Note that if the shotpoint time is changed after the event has been created, the event will not update automatically. For that, a trigger or cron event that periodically refreshes the entire table will be necessary.';
--
-- Name: events_timed_seq_match(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE FUNCTION _SURVEY__TEMPLATE_.events_timed_seq_match() RETURNS trigger
LANGUAGE plpgsql
AS $$
BEGIN
IF EXISTS (SELECT 1 FROM events_timed_seq WHERE id = NEW.id) THEN
DELETE FROM events_timed_seq WHERE id = NEW.id;
END IF;
INSERT INTO events_timed_seq (id, sequence, point)
(WITH seqs AS (
SELECT
e.id,
e.tstamp,
rls.sequence
FROM (events_timed e
LEFT JOIN raw_lines_summary rls ON (((e.tstamp >= rls.ts0) AND (e.tstamp <= rls.ts1))))
)
SELECT
seqs.id,
seqs.sequence,
shots.point
FROM (seqs
LEFT JOIN LATERAL ( SELECT rs.sequence,
rs.point
FROM raw_shots rs
ORDER BY (seqs.tstamp OPERATOR(public.<->) rs.tstamp)
LIMIT 1
) shots USING (sequence))
WHERE seqs.id = NEW.id AND sequence IS NOT NULL AND point IS NOT NULL);
RETURN NULL;
END;
$$;
ALTER FUNCTION _SURVEY__TEMPLATE_.events_timed_seq_match() OWNER TO postgres;
--
-- Name: events_timed events_timed_seq_match_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TRIGGER events_timed_seq_match_tg AFTER INSERT OR UPDATE ON _SURVEY__TEMPLATE_.events_timed FOR EACH ROW EXECUTE FUNCTION _SURVEY__TEMPLATE_.events_timed_seq_match();
--
-- Name: events_timed_seq_update_all(); Type: PROCEDURE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE PROCEDURE _SURVEY__TEMPLATE_.events_timed_seq_update_all()
LANGUAGE sql
AS $$
TRUNCATE events_timed_seq;
INSERT INTO events_timed_seq (id, sequence, point)
(WITH seqs AS (
SELECT
e.id,
e.tstamp,
rls.sequence
FROM (events_timed e
LEFT JOIN raw_lines_summary rls ON (((e.tstamp >= rls.ts0) AND (e.tstamp <= rls.ts1))))
)
SELECT
seqs.id,
seqs.sequence,
shots.point
FROM (seqs
LEFT JOIN LATERAL ( SELECT rs.sequence,
rs.point
FROM raw_shots rs
ORDER BY (seqs.tstamp OPERATOR(public.<->) rs.tstamp)
LIMIT 1
) shots USING (sequence))
WHERE seqs.id IS NOT NULL AND sequence IS NOT NULL AND point IS NOT NULL);
$$;
ALTER PROCEDURE _SURVEY__TEMPLATE_.events_timed_seq_update_all() OWNER TO postgres;
-- --
-- Name: events; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- Name: events; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
-- --
@@ -498,16 +554,18 @@ CREATE VIEW _SURVEY__TEMPLATE_.events AS
UNION UNION
SELECT 'timed'::text AS type, SELECT 'timed'::text AS type,
false AS virtual, false AS virtual,
t.sequence, rs.sequence,
t.point, rs.point,
t.id, t.id,
t.remarks, t.remarks,
t.line, rs.line,
t.objref, rs.objref,
t.tstamp, t.tstamp,
t.hash, rs.hash,
t.geometry rs.geometry
FROM _SURVEY__TEMPLATE_.events_timed_seq t FROM ((_SURVEY__TEMPLATE_.events_timed t
LEFT JOIN _SURVEY__TEMPLATE_.events_timed_seq ts USING (id))
LEFT JOIN _SURVEY__TEMPLATE_.raw_shots rs USING (sequence, point))
UNION UNION
SELECT 'midnight shot'::text AS type, SELECT 'midnight shot'::text AS type,
true AS virtual, true AS virtual,