mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 11:37:08 +00:00
Add event tables and views.
Events can be associated either with a timestamp *or* with a sequence + shotpoint (but not both, for data integrity reasons). Events and shotpoints can also have “labels” associated with them. The difference between a comment and a label is that the former is free text while the latter is predefined and has associated properties (currently only for display, but could also have QC related properties such as ensuring that there is only one “FSP” label per sequence and so on). The `events` view puts everything together into a coherent view. Note that this view may produce multiple rows for the same timestamp or shotpoint, for instance when the event has both a text comment and one or more labels.
This commit is contained in:
@@ -172,6 +172,355 @@ NOTE: The proper way of doing this would be to define an EngineeringCRS in the s
|
||||
|
||||
SET default_tablespace = '';
|
||||
|
||||
--
|
||||
-- Name: events_seq; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
CREATE TABLE _SURVEY__TEMPLATE_.events_seq (
|
||||
id integer NOT NULL,
|
||||
remarks text NOT NULL,
|
||||
sequence integer NOT NULL,
|
||||
shot_number integer NOT NULL
|
||||
);
|
||||
|
||||
|
||||
ALTER TABLE _SURVEY__TEMPLATE_.events_seq OWNER TO postgres;
|
||||
|
||||
--
|
||||
-- Name: TABLE events_seq; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
COMMENT ON TABLE _SURVEY__TEMPLATE_.events_seq IS 'Events associated with a specific sequence / shot number. The sequence must exist in raw_lines but the shot number need not (yet) exist. This is intended so that people can make entries ahead of time.';
|
||||
|
||||
|
||||
--
|
||||
-- Name: events_seq_labels; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
CREATE TABLE _SURVEY__TEMPLATE_.events_seq_labels (
|
||||
id integer NOT NULL,
|
||||
label text NOT NULL
|
||||
);
|
||||
|
||||
|
||||
ALTER TABLE _SURVEY__TEMPLATE_.events_seq_labels OWNER TO postgres;
|
||||
|
||||
--
|
||||
-- Name: TABLE events_seq_labels; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
COMMENT ON TABLE _SURVEY__TEMPLATE_.events_seq_labels IS 'Associates labels with events in events_seq.';
|
||||
|
||||
|
||||
--
|
||||
-- Name: events_seq_shots_labels; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
CREATE TABLE _SURVEY__TEMPLATE_.events_seq_shots_labels (
|
||||
sequence integer NOT NULL,
|
||||
shot_number integer NOT NULL,
|
||||
label text NOT NULL
|
||||
);
|
||||
|
||||
|
||||
ALTER TABLE _SURVEY__TEMPLATE_.events_seq_shots_labels OWNER TO postgres;
|
||||
|
||||
--
|
||||
-- Name: TABLE events_seq_shots_labels; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
COMMENT ON TABLE _SURVEY__TEMPLATE_.events_seq_shots_labels IS 'Associates labels with shots. This is intended for cases where a shot needs a label but no accompanying comment (FSP, LSP, etc.) so it makes no sense to add an entry in events_seq. It does require that the referenced sequence exist in raw_lines.
|
||||
';
|
||||
|
||||
|
||||
--
|
||||
-- Name: events_timed; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
CREATE TABLE _SURVEY__TEMPLATE_.events_timed (
|
||||
id integer NOT NULL,
|
||||
remarks text NOT NULL,
|
||||
ts0 timestamp with time zone NOT NULL,
|
||||
ts1 timestamp with time zone
|
||||
);
|
||||
|
||||
|
||||
ALTER TABLE _SURVEY__TEMPLATE_.events_timed OWNER TO postgres;
|
||||
|
||||
--
|
||||
-- Name: TABLE events_timed; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
COMMENT ON TABLE _SURVEY__TEMPLATE_.events_timed IS 'Events associated with a specific timestamp. The timestamp may or may not be within an acquisition sequence.
|
||||
|
||||
This table actually supports intervals (start + end times) but this is not intended to be used for the time being.
|
||||
|
||||
Events that occur within a sequence can be associated with dynamically, via a view.
|
||||
';
|
||||
|
||||
|
||||
--
|
||||
-- Name: final_shots; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
CREATE TABLE _SURVEY__TEMPLATE_.final_shots (
|
||||
sequence integer NOT NULL,
|
||||
line integer NOT NULL,
|
||||
point integer NOT NULL,
|
||||
objref integer NOT NULL,
|
||||
tstamp timestamp with time zone NOT NULL,
|
||||
hash text NOT NULL,
|
||||
geometry public.geometry(Point,_EPSG__CODE_)
|
||||
);
|
||||
|
||||
|
||||
ALTER TABLE _SURVEY__TEMPLATE_.final_shots OWNER TO postgres;
|
||||
|
||||
--
|
||||
-- Name: preplot_points; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
CREATE TABLE _SURVEY__TEMPLATE_.preplot_points (
|
||||
line integer NOT NULL,
|
||||
point integer NOT NULL,
|
||||
class character(1) NOT NULL,
|
||||
geometry public.geometry(Point,_EPSG__CODE_) NOT NULL
|
||||
);
|
||||
|
||||
|
||||
ALTER TABLE _SURVEY__TEMPLATE_.preplot_points OWNER TO postgres;
|
||||
|
||||
--
|
||||
-- Name: TABLE preplot_points; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
COMMENT ON TABLE _SURVEY__TEMPLATE_.preplot_points IS 'The preplot_points table holds each individual sailline preplot.
|
||||
|
||||
This is at present the only category for which we hold all individual positions.
|
||||
We do this in order to be able to detect shots that do not have a preplot and
|
||||
missed shots in acquisition and deliverable lines.
|
||||
';
|
||||
|
||||
|
||||
--
|
||||
-- Name: raw_lines; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
CREATE TABLE _SURVEY__TEMPLATE_.raw_lines (
|
||||
sequence integer NOT NULL,
|
||||
line integer NOT NULL,
|
||||
remarks text DEFAULT ''::text NOT NULL,
|
||||
ntbp boolean DEFAULT false NOT NULL,
|
||||
incr boolean NOT NULL
|
||||
);
|
||||
|
||||
|
||||
ALTER TABLE _SURVEY__TEMPLATE_.raw_lines OWNER TO postgres;
|
||||
|
||||
--
|
||||
-- Name: raw_shots; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
CREATE TABLE _SURVEY__TEMPLATE_.raw_shots (
|
||||
sequence integer NOT NULL,
|
||||
line integer NOT NULL,
|
||||
point integer NOT NULL,
|
||||
objref integer NOT NULL,
|
||||
tstamp timestamp with time zone NOT NULL,
|
||||
hash text NOT NULL,
|
||||
geometry public.geometry(Point,_EPSG__CODE_)
|
||||
);
|
||||
|
||||
|
||||
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: events; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
CREATE VIEW _SURVEY__TEMPLATE_.events AS
|
||||
WITH seqs AS (
|
||||
SELECT e.id,
|
||||
e.remarks,
|
||||
e.ts0,
|
||||
e.ts1,
|
||||
rls.sequence
|
||||
FROM (_SURVEY__TEMPLATE_.events_timed e
|
||||
LEFT JOIN _SURVEY__TEMPLATE_.raw_lines_summary rls ON (((e.ts0 >= rls.ts0) AND (e.ts0 <= rls.ts1))))
|
||||
), events_timed_sequences AS (
|
||||
SELECT seqs.sequence,
|
||||
seqs.id,
|
||||
seqs.remarks,
|
||||
seqs.ts0,
|
||||
seqs.ts1,
|
||||
shots.line,
|
||||
shots.point,
|
||||
shots.objref,
|
||||
shots.tstamp,
|
||||
shots.hash,
|
||||
shots.geometry
|
||||
FROM (seqs
|
||||
LEFT JOIN LATERAL ( SELECT fs.sequence,
|
||||
fs.line,
|
||||
fs.point,
|
||||
fs.objref,
|
||||
fs.tstamp,
|
||||
fs.hash,
|
||||
fs.geometry
|
||||
FROM _SURVEY__TEMPLATE_.final_shots fs
|
||||
ORDER BY (seqs.ts0 OPERATOR(public.<->) fs.tstamp)
|
||||
LIMIT 1) shots USING (sequence))
|
||||
)
|
||||
SELECT 'timed'::text AS source,
|
||||
events_timed_sequences.id,
|
||||
events_timed_sequences.sequence,
|
||||
events_timed_sequences.point AS shot_number,
|
||||
events_timed_sequences.ts0,
|
||||
events_timed_sequences.ts1,
|
||||
NULL::text AS label,
|
||||
events_timed_sequences.remarks
|
||||
FROM events_timed_sequences
|
||||
UNION
|
||||
SELECT 'shot_labels'::text AS source,
|
||||
NULL::integer AS id,
|
||||
essl.sequence,
|
||||
essl.shot_number,
|
||||
rs.tstamp AS ts0,
|
||||
NULL::timestamp with time zone AS ts1,
|
||||
essl.label,
|
||||
NULL::text AS remarks
|
||||
FROM (_SURVEY__TEMPLATE_.events_seq_shots_labels essl
|
||||
LEFT JOIN _SURVEY__TEMPLATE_.raw_shots rs ON (((essl.sequence = rs.sequence) AND (essl.shot_number = rs.point))))
|
||||
UNION
|
||||
SELECT 'seq'::text AS source,
|
||||
es.id,
|
||||
es.sequence,
|
||||
es.shot_number,
|
||||
rs.tstamp AS ts0,
|
||||
NULL::timestamp with time zone AS ts1,
|
||||
NULL::text AS label,
|
||||
es.remarks
|
||||
FROM (_SURVEY__TEMPLATE_.events_seq es
|
||||
LEFT JOIN _SURVEY__TEMPLATE_.raw_shots rs ON (((es.sequence = rs.sequence) AND (es.shot_number = rs.point))))
|
||||
UNION
|
||||
SELECT 'seq_labels'::text AS source,
|
||||
esl.id,
|
||||
es.sequence,
|
||||
es.shot_number,
|
||||
rs.tstamp AS ts0,
|
||||
NULL::timestamp with time zone AS ts1,
|
||||
esl.label,
|
||||
NULL::text AS remarks
|
||||
FROM ((_SURVEY__TEMPLATE_.events_seq_labels esl
|
||||
JOIN _SURVEY__TEMPLATE_.events_seq es USING (id))
|
||||
LEFT JOIN _SURVEY__TEMPLATE_.raw_shots rs ON (((es.sequence = rs.sequence) AND (es.shot_number = rs.point))));
|
||||
|
||||
|
||||
ALTER TABLE _SURVEY__TEMPLATE_.events OWNER TO postgres;
|
||||
|
||||
--
|
||||
-- Name: events_seq_id_seq; Type: SEQUENCE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
CREATE SEQUENCE _SURVEY__TEMPLATE_.events_seq_id_seq
|
||||
AS integer
|
||||
START WITH 1
|
||||
INCREMENT BY 1
|
||||
NO MINVALUE
|
||||
NO MAXVALUE
|
||||
CACHE 1;
|
||||
|
||||
|
||||
ALTER TABLE _SURVEY__TEMPLATE_.events_seq_id_seq OWNER TO postgres;
|
||||
|
||||
--
|
||||
-- Name: events_seq_id_seq; Type: SEQUENCE OWNED BY; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
ALTER SEQUENCE _SURVEY__TEMPLATE_.events_seq_id_seq OWNED BY _SURVEY__TEMPLATE_.events_seq.id;
|
||||
|
||||
|
||||
--
|
||||
-- Name: events_timed_id_seq; Type: SEQUENCE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
CREATE SEQUENCE _SURVEY__TEMPLATE_.events_timed_id_seq
|
||||
AS integer
|
||||
START WITH 1
|
||||
INCREMENT BY 1
|
||||
NO MINVALUE
|
||||
NO MAXVALUE
|
||||
CACHE 1;
|
||||
|
||||
|
||||
ALTER TABLE _SURVEY__TEMPLATE_.events_timed_id_seq OWNER TO postgres;
|
||||
|
||||
--
|
||||
-- Name: events_timed_id_seq; Type: SEQUENCE OWNED BY; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
ALTER SEQUENCE _SURVEY__TEMPLATE_.events_timed_id_seq OWNED BY _SURVEY__TEMPLATE_.events_timed.id;
|
||||
|
||||
|
||||
--
|
||||
-- Name: events_timed_labels; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
CREATE TABLE _SURVEY__TEMPLATE_.events_timed_labels (
|
||||
id integer NOT NULL,
|
||||
label text NOT NULL
|
||||
);
|
||||
|
||||
|
||||
ALTER TABLE _SURVEY__TEMPLATE_.events_timed_labels OWNER TO postgres;
|
||||
|
||||
--
|
||||
-- Name: TABLE events_timed_labels; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
COMMENT ON TABLE _SURVEY__TEMPLATE_.events_timed_labels IS 'Associates labels with events in events_timed.';
|
||||
|
||||
|
||||
--
|
||||
-- Name: file_data; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
@@ -249,49 +598,6 @@ CREATE TABLE _SURVEY__TEMPLATE_.final_lines_files (
|
||||
|
||||
ALTER TABLE _SURVEY__TEMPLATE_.final_lines_files OWNER TO postgres;
|
||||
|
||||
--
|
||||
-- Name: final_shots; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
CREATE TABLE _SURVEY__TEMPLATE_.final_shots (
|
||||
sequence integer NOT NULL,
|
||||
line integer NOT NULL,
|
||||
point integer NOT NULL,
|
||||
objref integer NOT NULL,
|
||||
tstamp timestamp with time zone NOT NULL,
|
||||
hash text NOT NULL,
|
||||
geometry public.geometry(Point,_EPSG__CODE_)
|
||||
);
|
||||
|
||||
|
||||
ALTER TABLE _SURVEY__TEMPLATE_.final_shots OWNER TO postgres;
|
||||
|
||||
--
|
||||
-- Name: preplot_points; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
CREATE TABLE _SURVEY__TEMPLATE_.preplot_points (
|
||||
line integer NOT NULL,
|
||||
point integer NOT NULL,
|
||||
class character(1) NOT NULL,
|
||||
geometry public.geometry(Point,_EPSG__CODE_) NOT NULL
|
||||
);
|
||||
|
||||
|
||||
ALTER TABLE _SURVEY__TEMPLATE_.preplot_points OWNER TO postgres;
|
||||
|
||||
--
|
||||
-- Name: TABLE preplot_points; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
COMMENT ON TABLE _SURVEY__TEMPLATE_.preplot_points IS 'The preplot_points table holds each individual sailline preplot.
|
||||
|
||||
This is at present the only category for which we hold all individual positions.
|
||||
We do this in order to be able to detect shots that do not have a preplot and
|
||||
missed shots in acquisition and deliverable lines.
|
||||
';
|
||||
|
||||
|
||||
--
|
||||
-- Name: final_lines_summary; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
@@ -412,6 +718,25 @@ CREATE TABLE _SURVEY__TEMPLATE_.info (
|
||||
|
||||
ALTER TABLE _SURVEY__TEMPLATE_.info OWNER TO postgres;
|
||||
|
||||
--
|
||||
-- Name: labels; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
CREATE TABLE _SURVEY__TEMPLATE_.labels (
|
||||
name text NOT NULL,
|
||||
data jsonb NOT NULL
|
||||
);
|
||||
|
||||
|
||||
ALTER TABLE _SURVEY__TEMPLATE_.labels OWNER TO postgres;
|
||||
|
||||
--
|
||||
-- Name: TABLE labels; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
COMMENT ON TABLE _SURVEY__TEMPLATE_.labels IS 'Labels to attach to events, shots, or anything else really. Each level consists of a (unique) name and a JSON object with arbitrary label properties (intended to be used for label descriptions, colours, etc.)';
|
||||
|
||||
|
||||
--
|
||||
-- Name: preplot_lines; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
@@ -499,21 +824,6 @@ 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: raw_lines; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
CREATE TABLE _SURVEY__TEMPLATE_.raw_lines (
|
||||
sequence integer NOT NULL,
|
||||
line integer NOT NULL,
|
||||
remarks text DEFAULT ''::text NOT NULL,
|
||||
ntbp boolean DEFAULT false NOT NULL,
|
||||
incr boolean NOT NULL
|
||||
);
|
||||
|
||||
|
||||
ALTER TABLE _SURVEY__TEMPLATE_.raw_lines OWNER TO postgres;
|
||||
|
||||
--
|
||||
-- Name: raw_lines_files; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
@@ -526,63 +836,6 @@ CREATE TABLE _SURVEY__TEMPLATE_.raw_lines_files (
|
||||
|
||||
ALTER TABLE _SURVEY__TEMPLATE_.raw_lines_files OWNER TO postgres;
|
||||
|
||||
--
|
||||
-- Name: raw_shots; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
CREATE TABLE _SURVEY__TEMPLATE_.raw_shots (
|
||||
sequence integer NOT NULL,
|
||||
line integer NOT NULL,
|
||||
point integer NOT NULL,
|
||||
objref integer NOT NULL,
|
||||
tstamp timestamp with time zone NOT NULL,
|
||||
hash text NOT NULL,
|
||||
geometry public.geometry(Point,_EPSG__CODE_)
|
||||
);
|
||||
|
||||
|
||||
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
|
||||
--
|
||||
@@ -654,6 +907,52 @@ 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: events_seq id; Type: DEFAULT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_seq ALTER COLUMN id SET DEFAULT nextval('_SURVEY__TEMPLATE_.events_seq_id_seq'::regclass);
|
||||
|
||||
|
||||
--
|
||||
-- Name: events_timed id; Type: DEFAULT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
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_shots_labels events_seq_shots_labels_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_seq_shots_labels
|
||||
ADD CONSTRAINT events_seq_shots_labels_pkey PRIMARY KEY (sequence, shot_number, label);
|
||||
|
||||
|
||||
--
|
||||
-- Name: events_timed_labels events_timed_labels_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_timed_labels
|
||||
ADD CONSTRAINT events_timed_labels_pkey PRIMARY KEY (id, label);
|
||||
|
||||
|
||||
--
|
||||
-- Name: events_timed events_timed_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_timed
|
||||
ADD CONSTRAINT events_timed_pkey PRIMARY KEY (id);
|
||||
|
||||
|
||||
--
|
||||
-- Name: file_data file_data_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
@@ -710,6 +1009,14 @@ ALTER TABLE ONLY _SURVEY__TEMPLATE_.info
|
||||
ADD CONSTRAINT info_pkey PRIMARY KEY (key);
|
||||
|
||||
|
||||
--
|
||||
-- Name: labels labels_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
ALTER TABLE ONLY _SURVEY__TEMPLATE_.labels
|
||||
ADD CONSTRAINT labels_pkey PRIMARY KEY (name);
|
||||
|
||||
|
||||
--
|
||||
-- Name: preplot_lines preplot_lines_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
@@ -750,6 +1057,76 @@ ALTER TABLE ONLY _SURVEY__TEMPLATE_.raw_shots
|
||||
ADD CONSTRAINT raw_shots_pkey PRIMARY KEY (sequence, point);
|
||||
|
||||
|
||||
--
|
||||
-- Name: events_seq_sequence_idx; Type: INDEX; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
CREATE INDEX events_seq_sequence_idx ON _SURVEY__TEMPLATE_.events_seq USING btree (sequence);
|
||||
|
||||
|
||||
--
|
||||
-- Name: events_timed_ts0_idx; Type: INDEX; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
CREATE INDEX events_timed_ts0_idx ON _SURVEY__TEMPLATE_.events_timed USING btree (ts0);
|
||||
|
||||
|
||||
--
|
||||
-- Name: events_seq_labels events_seq_labels_id_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_seq_labels
|
||||
ADD CONSTRAINT events_seq_labels_id_fkey FOREIGN KEY (id) REFERENCES _SURVEY__TEMPLATE_.events_seq(id);
|
||||
|
||||
|
||||
--
|
||||
-- Name: events_seq_labels events_seq_labels_label_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_seq_labels
|
||||
ADD CONSTRAINT events_seq_labels_label_fkey FOREIGN KEY (label) REFERENCES _SURVEY__TEMPLATE_.labels(name) ON UPDATE CASCADE ON DELETE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Name: events_seq events_seq_sequence_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_seq
|
||||
ADD CONSTRAINT events_seq_sequence_fkey FOREIGN KEY (sequence) REFERENCES _SURVEY__TEMPLATE_.raw_lines(sequence) ON UPDATE CASCADE ON DELETE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Name: events_seq_shots_labels events_seq_shots_labels_label_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_seq_shots_labels
|
||||
ADD CONSTRAINT events_seq_shots_labels_label_fkey FOREIGN KEY (label) REFERENCES _SURVEY__TEMPLATE_.labels(name) ON UPDATE CASCADE ON DELETE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Name: events_seq_shots_labels events_seq_shots_labels_sequence_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_seq_shots_labels
|
||||
ADD CONSTRAINT events_seq_shots_labels_sequence_fkey FOREIGN KEY (sequence) REFERENCES _SURVEY__TEMPLATE_.raw_lines(sequence) ON UPDATE CASCADE ON DELETE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Name: events_timed_labels events_timed_labels_id_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_timed_labels
|
||||
ADD CONSTRAINT events_timed_labels_id_fkey FOREIGN KEY (id) REFERENCES _SURVEY__TEMPLATE_.events_timed(id) ON UPDATE CASCADE ON DELETE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Name: events_timed_labels events_timed_labels_label_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
ALTER TABLE ONLY _SURVEY__TEMPLATE_.events_timed_labels
|
||||
ADD CONSTRAINT events_timed_labels_label_fkey FOREIGN KEY (label) REFERENCES _SURVEY__TEMPLATE_.labels(name) ON UPDATE CASCADE ON DELETE CASCADE;
|
||||
|
||||
|
||||
--
|
||||
-- Name: file_data file_data_hash_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
||||
--
|
||||
|
||||
Reference in New Issue
Block a user