Update database templates to v0.4.5

This commit is contained in:
D. Berge
2023-11-02 20:15:51 +01:00
parent 402a3f9cce
commit a55d2cc6fc
2 changed files with 68 additions and 51 deletions

View File

@@ -1,5 +1,5 @@
\connect dougal
INSERT INTO public.info VALUES ('version', '{"db_schema": "0.4.2"}')
INSERT INTO public.info VALUES ('version', '{"db_schema": "0.4.5"}')
ON CONFLICT (key) DO UPDATE
SET value = public.info.value || '{"db_schema": "0.4.2"}' WHERE public.info.key = 'version';
SET value = public.info.value || '{"db_schema": "0.4.5"}' WHERE public.info.key = 'version';

View File

@@ -399,6 +399,62 @@ $$;
ALTER FUNCTION _SURVEY__TEMPLATE_.clear_shot_qc() OWNER TO postgres;
--
-- Name: event_log_uid_seq; Type: SEQUENCE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE SEQUENCE _SURVEY__TEMPLATE_.event_log_uid_seq
AS integer
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
ALTER TABLE _SURVEY__TEMPLATE_.event_log_uid_seq OWNER TO postgres;
SET default_tablespace = '';
SET default_table_access_method = heap;
--
-- Name: event_log_full; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TABLE _SURVEY__TEMPLATE_.event_log_full (
uid integer DEFAULT nextval('_SURVEY__TEMPLATE_.event_log_uid_seq'::regclass) NOT NULL,
id integer NOT NULL,
tstamp timestamp with time zone,
sequence integer,
point integer,
remarks text DEFAULT ''::text NOT NULL,
labels text[] DEFAULT ARRAY[]::text[] NOT NULL,
meta jsonb DEFAULT '{}'::jsonb NOT NULL,
validity tstzrange NOT NULL,
CONSTRAINT event_log_full_check CHECK ((((tstamp IS NOT NULL) AND (sequence IS NOT NULL) AND (point IS NOT NULL)) OR ((tstamp IS NOT NULL) AND (sequence IS NULL) AND (point IS NULL)) OR ((tstamp IS NULL) AND (sequence IS NOT NULL) AND (point IS NOT NULL)))),
CONSTRAINT event_log_full_validity_check CHECK ((NOT isempty(validity)))
);
ALTER TABLE _SURVEY__TEMPLATE_.event_log_full OWNER TO postgres;
--
-- Name: event_log_changes(timestamp with time zone); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE FUNCTION _SURVEY__TEMPLATE_.event_log_changes(ts0 timestamp with time zone) RETURNS SETOF _SURVEY__TEMPLATE_.event_log_full
LANGUAGE sql
AS $$
SELECT *
FROM event_log_full
WHERE lower(validity) > ts0 OR upper(validity) IS NOT NULL AND upper(validity) > ts0
ORDER BY lower(validity);
$$;
ALTER FUNCTION _SURVEY__TEMPLATE_.event_log_changes(ts0 timestamp with time zone) OWNER TO postgres;
--
-- Name: event_log_full_insert(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
@@ -881,46 +937,6 @@ $$;
ALTER FUNCTION _SURVEY__TEMPLATE_.ij_error(line double precision, point double precision, geom public.geometry) OWNER TO postgres;
--
-- Name: event_log_uid_seq; Type: SEQUENCE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE SEQUENCE _SURVEY__TEMPLATE_.event_log_uid_seq
AS integer
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1;
ALTER TABLE _SURVEY__TEMPLATE_.event_log_uid_seq OWNER TO postgres;
SET default_tablespace = '';
SET default_table_access_method = heap;
--
-- Name: event_log_full; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TABLE _SURVEY__TEMPLATE_.event_log_full (
uid integer DEFAULT nextval('_SURVEY__TEMPLATE_.event_log_uid_seq'::regclass) NOT NULL,
id integer NOT NULL,
tstamp timestamp with time zone,
sequence integer,
point integer,
remarks text DEFAULT ''::text NOT NULL,
labels text[] DEFAULT ARRAY[]::text[] NOT NULL,
meta jsonb DEFAULT '{}'::jsonb NOT NULL,
validity tstzrange NOT NULL,
CONSTRAINT event_log_full_check CHECK ((((tstamp IS NOT NULL) AND (sequence IS NOT NULL) AND (point IS NOT NULL)) OR ((tstamp IS NOT NULL) AND (sequence IS NULL) AND (point IS NULL)) OR ((tstamp IS NULL) AND (sequence IS NOT NULL) AND (point IS NOT NULL)))),
CONSTRAINT event_log_full_validity_check CHECK ((NOT isempty(validity)))
);
ALTER TABLE _SURVEY__TEMPLATE_.event_log_full OWNER TO postgres;
--
-- Name: event_log; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
@@ -1519,9 +1535,9 @@ CREATE VIEW _SURVEY__TEMPLATE_.final_lines_summary AS
s.ts1,
(s.ts1 - s.ts0) AS duration,
s.num_points,
( SELECT count(*) AS count
FROM _SURVEY__TEMPLATE_.missing_sequence_final_points
WHERE missing_sequence_final_points.sequence = s.sequence) AS missing_shots,
(( SELECT count(*) AS count
FROM _SURVEY__TEMPLATE_.preplot_points
WHERE ((preplot_points.line = fl.line) AND (((preplot_points.point >= s.fsp) AND (preplot_points.point <= s.lsp)) OR ((preplot_points.point >= s.lsp) AND (preplot_points.point <= s.fsp))))) - s.num_points) AS missing_shots,
s.length,
s.azimuth,
fl.remarks,
@@ -2077,10 +2093,10 @@ CREATE VIEW _SURVEY__TEMPLATE_.preplot_summary AS
ALTER TABLE _SURVEY__TEMPLATE_.preplot_summary OWNER TO postgres;
--
-- Name: project_summary; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
-- Name: project_summary; Type: MATERIALIZED VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_.project_summary AS
CREATE MATERIALIZED VIEW _SURVEY__TEMPLATE_.project_summary AS
WITH fls AS (
SELECT avg((final_lines_summary.duration / ((final_lines_summary.num_points - 1))::double precision)) AS shooting_rate,
avg((final_lines_summary.length / date_part('epoch'::text, final_lines_summary.duration))) AS speed,
@@ -2123,7 +2139,8 @@ CREATE VIEW _SURVEY__TEMPLATE_.project_summary AS
fls.speed AS shooting_rate
FROM _SURVEY__TEMPLATE_.preplot_summary ps,
fls,
project;
project
WITH NO DATA;
ALTER TABLE _SURVEY__TEMPLATE_.project_summary OWNER TO postgres;
@@ -2168,9 +2185,9 @@ CREATE VIEW _SURVEY__TEMPLATE_.raw_lines_summary AS
(s.ts1 - s.ts0) AS duration,
s.num_points,
s.num_preplots,
(SELECT count(*) AS count
FROM _SURVEY__TEMPLATE_.missing_sequence_raw_points
WHERE missing_sequence_raw_points.sequence = s.sequence) AS missing_shots,
(( SELECT count(*) AS count
FROM _SURVEY__TEMPLATE_.preplot_points
WHERE ((preplot_points.line = rl.line) AND (((preplot_points.point >= s.fsp) AND (preplot_points.point <= s.lsp)) OR ((preplot_points.point >= s.lsp) AND (preplot_points.point <= s.fsp))))) - s.num_preplots) AS missing_shots,
s.length,
s.azimuth,
rl.remarks,