From 242d35ec809d4110ccb7e4270ef71749013bc24d Mon Sep 17 00:00:00 2001 From: "D. Berge" Date: Wed, 26 Aug 2020 20:14:07 +0200 Subject: [PATCH] Update schema: add project summary tables --- etc/db/schema-template.sql | 123 +++++++++++++++++++++++++++++++++++++ 1 file changed, 123 insertions(+) diff --git a/etc/db/schema-template.sql b/etc/db/schema-template.sql index 1c08e7d..e6edbe6 100644 --- a/etc/db/schema-template.sql +++ b/etc/db/schema-template.sql @@ -808,6 +808,25 @@ ALTER TABLE _SURVEY__TEMPLATE_.final_shots_ij_error OWNER TO postgres; COMMENT ON VIEW _SURVEY__TEMPLATE_.final_shots_ij_error IS 'Shows the inline / crossline error of final shots.'; +-- +-- Name: final_shots_saillines; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +CREATE VIEW _SURVEY__TEMPLATE_.final_shots_saillines AS + SELECT fl.line AS sailline, + fs.sequence, + fs.line, + fs.point, + fs.objref, + fs.tstamp, + fs.hash, + fs.geometry + FROM (_SURVEY__TEMPLATE_.final_lines fl + JOIN _SURVEY__TEMPLATE_.final_shots fs USING (sequence)); + + +ALTER TABLE _SURVEY__TEMPLATE_.final_shots_saillines OWNER TO postgres; + -- -- Name: info; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- @@ -915,6 +934,91 @@ ALTER TABLE _SURVEY__TEMPLATE_.preplot_lines_summary OWNER TO postgres; COMMENT ON VIEW _SURVEY__TEMPLATE_.preplot_lines_summary IS 'Summarises ''V'' (vessel sailline) preplot lines.'; +-- +-- Name: preplot_points_count; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +CREATE VIEW _SURVEY__TEMPLATE_.preplot_points_count AS + SELECT pp.line, + pp.point, + count(fss.sequence) AS count + FROM (_SURVEY__TEMPLATE_.preplot_points pp + LEFT JOIN _SURVEY__TEMPLATE_.final_shots_saillines fss ON (((pp.line = fss.sailline) AND (pp.point = fss.point)))) + WHERE (pp.class = 'V'::bpchar) + GROUP BY pp.line, pp.point; + + +ALTER TABLE _SURVEY__TEMPLATE_.preplot_points_count OWNER TO postgres; + +-- +-- Name: preplot_summary; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +CREATE VIEW _SURVEY__TEMPLATE_.preplot_summary AS + SELECT count(*) AS total, + count(*) FILTER (WHERE (ppc.count = 0)) AS virgin, + count(*) FILTER (WHERE (ppc.count = 1)) AS prime, + count(*) FILTER (WHERE (ppc.count > 1)) AS other, + count(*) FILTER (WHERE ((pp.ntba IS TRUE) OR (pl.ntba IS TRUE))) AS ntba, + count(*) FILTER (WHERE ((ppc.count = 0) AND (pp.ntba IS NOT TRUE) AND (pl.ntba IS NOT TRUE))) AS remaining + FROM ((_SURVEY__TEMPLATE_.preplot_points_count ppc + JOIN _SURVEY__TEMPLATE_.preplot_points pp USING (line, point)) + JOIN _SURVEY__TEMPLATE_.preplot_lines pl USING (line)); + + +ALTER TABLE _SURVEY__TEMPLATE_.preplot_summary OWNER TO postgres; + +-- +-- Name: project_summary; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +CREATE 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, + sum(final_lines_summary.duration) AS prod_duration, + sum(final_lines_summary.length) AS prod_distance + FROM _SURVEY__TEMPLATE_.final_lines_summary + ), project AS ( + SELECT p.pid, + p.name, + p.schema + FROM public.projects p + WHERE (current_setting('search_path'::text) ~~ (p.schema || '%'::text)) + ) + SELECT project.pid, + project.name, + ( SELECT count(*) AS count + FROM _SURVEY__TEMPLATE_.preplot_lines + WHERE (preplot_lines.class = 'V'::bpchar)) AS lines, + ps.total, + ps.virgin, + ps.prime, + ps.other, + ps.ntba, + ps.remaining, + ( SELECT to_json(fs.*) AS to_json + FROM _SURVEY__TEMPLATE_.final_shots fs + ORDER BY fs.tstamp + LIMIT 1) AS fsp, + ( SELECT to_json(fs.*) AS to_json + FROM _SURVEY__TEMPLATE_.final_shots fs + ORDER BY fs.tstamp DESC + LIMIT 1) AS lsp, + ( SELECT count(*) AS count + FROM _SURVEY__TEMPLATE_.raw_lines rl) AS seq_raw, + ( SELECT count(*) AS count + FROM _SURVEY__TEMPLATE_.final_lines rl) AS seq_final, + fls.prod_duration, + fls.prod_distance, + fls.speed AS shooting_rate + FROM _SURVEY__TEMPLATE_.preplot_summary ps, + fls, + project; + + +ALTER TABLE _SURVEY__TEMPLATE_.project_summary OWNER TO postgres; + -- -- Name: raw_lines_files; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres -- @@ -998,6 +1102,25 @@ ALTER TABLE _SURVEY__TEMPLATE_.raw_shots_ij_error OWNER TO postgres; COMMENT ON VIEW _SURVEY__TEMPLATE_.raw_shots_ij_error IS 'Shows the inline / crossline error of raw shots.'; +-- +-- Name: raw_shots_saillines; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +CREATE VIEW _SURVEY__TEMPLATE_.raw_shots_saillines AS + SELECT rl.line AS sailline, + rs.sequence, + rs.line, + rs.point, + rs.objref, + rs.tstamp, + rs.hash, + rs.geometry + FROM (_SURVEY__TEMPLATE_.final_lines rl + JOIN _SURVEY__TEMPLATE_.final_shots rs USING (sequence)); + + +ALTER TABLE _SURVEY__TEMPLATE_.raw_shots_saillines OWNER TO postgres; + -- -- Name: sequences_summary; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres --