diff --git a/etc/db/schema-template.sql b/etc/db/schema-template.sql index 8a827d8..f68771f 100644 --- a/etc/db/schema-template.sql +++ b/etc/db/schema-template.sql @@ -543,6 +543,77 @@ CREATE TABLE _SURVEY__TEMPLATE_.raw_shots ( ALTER TABLE _SURVEY__TEMPLATE_.raw_shots OWNER TO postgres; +-- +-- Name: raw_lines_summary; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +CREATE VIEW _SURVEY__TEMPLATE_.raw_lines_summary AS + WITH summary AS ( + SELECT DISTINCT rs.sequence, + first_value(rs.point) OVER w AS fsp, + last_value(rs.point) OVER w AS lsp, + first_value(rs.tstamp) OVER w AS ts0, + last_value(rs.tstamp) OVER w AS ts1, + count(rs.point) OVER w AS num_points, + count(pp.point) OVER w AS num_preplots, + public.st_distance(first_value(rs.geometry) OVER w, last_value(rs.geometry) OVER w) AS length, + ((public.st_azimuth(first_value(rs.geometry) OVER w, last_value(rs.geometry) OVER w) * (180)::double precision) / pi()) AS azimuth + FROM (_SURVEY__TEMPLATE_.raw_shots rs + LEFT JOIN _SURVEY__TEMPLATE_.preplot_points pp USING (line, point)) + WINDOW w AS (PARTITION BY rs.sequence ORDER BY rs.tstamp ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) + ) + SELECT rl.sequence, + rl.line, + s.fsp, + s.lsp, + s.ts0, + s.ts1, + (s.ts1 - s.ts0) AS duration, + s.num_points, + s.num_preplots, + (( 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 + FROM (summary s + JOIN _SURVEY__TEMPLATE_.raw_lines rl USING (sequence)); + + +ALTER TABLE _SURVEY__TEMPLATE_.raw_lines_summary OWNER TO postgres; + +-- +-- Name: raw_lines_summary_geometry; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres +-- + +CREATE VIEW _SURVEY__TEMPLATE_.raw_lines_summary_geometry AS + WITH g AS ( + SELECT rs.sequence, + public.st_makeline(public.st_transform(rs.geometry, 4326) ORDER BY rs.tstamp) AS geometry + FROM (_SURVEY__TEMPLATE_.raw_shots rs + JOIN _SURVEY__TEMPLATE_.raw_lines_summary USING (sequence)) + GROUP BY rs.sequence + ) + SELECT rls.sequence, + rls.line, + rls.fsp, + rls.lsp, + rls.ts0, + rls.ts1, + rls.duration, + rls.num_points, + rls.missing_shots, + rls.length, + rls.azimuth, + rls.remarks, + g.geometry + FROM (_SURVEY__TEMPLATE_.raw_lines_summary rls + JOIN g USING (sequence)); + + +ALTER TABLE _SURVEY__TEMPLATE_.raw_lines_summary_geometry OWNER TO postgres; + -- -- Name: raw_shots_ij_error; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres --