Update SQL schema.

- The raw_shots and final_shots tables contain *shots*,
  as the name says, and nothing else.

- The objref is made an integer. This is consistent with
  P1/11 usage and for anything else a relation can be used.

- Raw and final shot tables also include the corresponding
  preplot line as well as the shot number. The preplot line
  is explicit in the P1/11s that we have seen and can otherwise
  be derived from the source geometry in the P1/11 or P1/90
  headers (provided those headers are correct). It is the
  import process' business to figure out what the preplot
  lines are if those are not explicitly given in the data.

- As a result of the above, some of the views have been
  re-written, hopefully in a simpler way.

- The shot_count view has been removed as it was neither used
  nor useful.
This commit is contained in:
D. Berge
2020-08-10 22:43:07 +02:00
parent a0faa51602
commit 09e5d9048a

View File

@@ -228,6 +228,15 @@ CREATE TABLE _SURVEY__TEMPLATE_.final_lines (
ALTER TABLE _SURVEY__TEMPLATE_.final_lines OWNER TO postgres;
--
-- Name: TABLE final_lines; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON TABLE _SURVEY__TEMPLATE_.final_lines IS 'This is the analogue of raw_lines but for final data. Note that there is no ntbp column: this is because we expect that a line that has been NTBP''d will simply not exist in final formor at least not in an importable way (e.g., it might/should have been renamed to NTBP or some such).
';
--
-- Name: final_lines_files; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
@@ -246,9 +255,9 @@ ALTER TABLE _SURVEY__TEMPLATE_.final_lines_files OWNER TO postgres;
CREATE TABLE _SURVEY__TEMPLATE_.final_shots (
sequence integer NOT NULL,
line integer NOT NULL,
point integer NOT NULL,
class character(1) NOT NULL,
objref character(4) NOT NULL,
objref integer NOT NULL,
tstamp timestamp with time zone NOT NULL,
hash text NOT NULL,
geometry public.geometry(Point,_EPSG__CODE_)
@@ -351,6 +360,46 @@ CREATE VIEW _SURVEY__TEMPLATE_.final_lines_summary_geometry AS
ALTER TABLE _SURVEY__TEMPLATE_.final_lines_summary_geometry OWNER TO postgres;
--
-- Name: final_shots_ij_error; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_.final_shots_ij_error AS
WITH shot_data AS (
SELECT fs.sequence,
fs.line,
fs.point,
fs.objref,
fs.tstamp,
fs.hash,
fs.geometry,
_SURVEY__TEMPLATE_.to_binning_grid(fs.geometry, _SURVEY__TEMPLATE_.binning_parameters()) AS ij
FROM _SURVEY__TEMPLATE_.final_shots fs
), bin AS (
SELECT (((_SURVEY__TEMPLATE_.binning_parameters() ->> 'I_width'::text))::numeric / ((_SURVEY__TEMPLATE_.binning_parameters() ->> 'I_inc'::text))::numeric) AS width,
(((_SURVEY__TEMPLATE_.binning_parameters() ->> 'J_width'::text))::numeric / ((_SURVEY__TEMPLATE_.binning_parameters() ->> 'J_inc'::text))::numeric) AS height
)
SELECT sd.sequence,
sd.line,
sd.point,
sd.objref,
sd.tstamp,
sd.hash,
((public.st_x(sd.ij) - (sd.line)::double precision) * (bin.width)::double precision) AS error_i,
((public.st_y(sd.ij) - (sd.point)::double precision) * (bin.height)::double precision) AS error_j
FROM shot_data sd,
bin;
ALTER TABLE _SURVEY__TEMPLATE_.final_shots_ij_error OWNER TO postgres;
--
-- Name: VIEW final_shots_ij_error; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON VIEW _SURVEY__TEMPLATE_.final_shots_ij_error IS 'Shows the inline / crossline error of final shots.';
--
-- Name: info; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
@@ -443,6 +492,13 @@ CREATE VIEW _SURVEY__TEMPLATE_.preplot_lines_summary AS
ALTER TABLE _SURVEY__TEMPLATE_.preplot_lines_summary OWNER TO postgres;
--
-- Name: VIEW preplot_lines_summary; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: 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
--
@@ -476,9 +532,9 @@ ALTER TABLE _SURVEY__TEMPLATE_.raw_lines_files OWNER TO postgres;
CREATE TABLE _SURVEY__TEMPLATE_.raw_shots (
sequence integer NOT NULL,
line integer NOT NULL,
point integer NOT NULL,
class character(1) NOT NULL,
objref character(4) NOT NULL,
objref integer NOT NULL,
tstamp timestamp with time zone NOT NULL,
hash text NOT NULL,
geometry public.geometry(Point,_EPSG__CODE_)
@@ -487,68 +543,33 @@ CREATE TABLE _SURVEY__TEMPLATE_.raw_shots (
ALTER TABLE _SURVEY__TEMPLATE_.raw_shots OWNER TO postgres;
--
-- Name: raw_shots_preplot_lines; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_.raw_shots_preplot_lines AS
WITH offsets AS (
SELECT fd.hash,
(((('S'::text || (json_array_elements.value ->> 2)) || (json_array_elements.value ->> 3)) || ' '::text))::character(4) AS objref,
((((json_array_elements.value ->> 4))::numeric / ((_SURVEY__TEMPLATE_.binning_parameters() ->> 'J_width'::text))::numeric))::integer AS di
FROM _SURVEY__TEMPLATE_.file_data fd,
LATERAL json_array_elements((fd.data -> 'offsets_p190'::text)) json_array_elements(value)
)
SELECT rl.sequence,
rs.point,
rs.class,
COALESCE(
CASE
WHEN rl.incr THEN (rl.line + o.di)
ELSE (rl.line - o.di)
END, rl.line) AS preplot_line
FROM (((_SURVEY__TEMPLATE_.raw_lines rl
JOIN _SURVEY__TEMPLATE_.raw_lines_files rlf USING (sequence))
JOIN _SURVEY__TEMPLATE_.raw_shots rs USING (sequence))
LEFT JOIN offsets o ON (((rlf.hash = o.hash) AND (rs.objref = o.objref))));
ALTER TABLE _SURVEY__TEMPLATE_.raw_shots_preplot_lines OWNER TO postgres;
--
-- Name: VIEW raw_shots_preplot_lines; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON VIEW _SURVEY__TEMPLATE_.raw_shots_preplot_lines IS 'This view correlates raw shots with their respective preplots, assuming that the preplots were specified as I, J line and point values as opposed to referring the preplot to the corresponding sailline.
';
--
-- Name: raw_shots_ij_error; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_.raw_shots_ij_error AS
WITH shot_data AS (
SELECT rspl.sequence,
rspl.point,
rspl.class,
rspl.preplot_line,
SELECT rs.sequence,
rs.line,
rs.point,
rs.objref,
rs.tstamp,
rs.hash,
rs.geometry,
_SURVEY__TEMPLATE_.to_binning_grid(rs.geometry, _SURVEY__TEMPLATE_.binning_parameters()) AS ij
FROM (_SURVEY__TEMPLATE_.raw_shots_preplot_lines rspl
JOIN _SURVEY__TEMPLATE_.raw_shots rs USING (sequence, point, class))
FROM _SURVEY__TEMPLATE_.raw_shots rs
), bin AS (
SELECT (((_SURVEY__TEMPLATE_.binning_parameters() ->> 'I_width'::text))::numeric / ((_SURVEY__TEMPLATE_.binning_parameters() ->> 'I_inc'::text))::numeric) AS width,
(((_SURVEY__TEMPLATE_.binning_parameters() ->> 'J_width'::text))::numeric / ((_SURVEY__TEMPLATE_.binning_parameters() ->> 'J_inc'::text))::numeric) AS height
)
SELECT sd.sequence,
sd.line,
sd.point,
sd.class,
((public.st_x(sd.ij) - (sd.preplot_line)::double precision) * (bin.width)::double precision) AS error_xline,
((public.st_y(sd.ij) - (sd.point)::double precision) * (bin.height)::double precision) AS error_inline
sd.objref,
sd.tstamp,
sd.hash,
((public.st_x(sd.ij) - (sd.line)::double precision) * (bin.width)::double precision) AS error_i,
((public.st_y(sd.ij) - (sd.point)::double precision) * (bin.height)::double precision) AS error_j
FROM shot_data sd,
bin;
@@ -556,24 +577,12 @@ CREATE VIEW _SURVEY__TEMPLATE_.raw_shots_ij_error AS
ALTER TABLE _SURVEY__TEMPLATE_.raw_shots_ij_error OWNER TO postgres;
--
-- Name: shot_count; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
-- Name: VIEW raw_shots_ij_error; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_.shot_count AS
SELECT rl.sequence,
rs.class,
count(rs.point) AS raw,
count(fs.point) AS final,
count(pp.point) AS preplot
FROM (((_SURVEY__TEMPLATE_.raw_lines rl
JOIN _SURVEY__TEMPLATE_.raw_shots rs USING (sequence))
LEFT JOIN _SURVEY__TEMPLATE_.final_shots fs USING (sequence, point, class))
LEFT JOIN _SURVEY__TEMPLATE_.preplot_points pp USING (line, point, class))
GROUP BY rl.sequence, rl.line, rs.class;
COMMENT ON VIEW _SURVEY__TEMPLATE_.raw_shots_ij_error IS 'Shows the inline / crossline error of raw shots.';
ALTER TABLE _SURVEY__TEMPLATE_.shot_count OWNER TO postgres;
--
-- Name: file_data file_data_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
@@ -619,7 +628,7 @@ ALTER TABLE ONLY _SURVEY__TEMPLATE_.final_lines
--
ALTER TABLE ONLY _SURVEY__TEMPLATE_.final_shots
ADD CONSTRAINT final_shots_pkey PRIMARY KEY (sequence, point, class);
ADD CONSTRAINT final_shots_pkey PRIMARY KEY (sequence, point);
--
@@ -667,7 +676,7 @@ ALTER TABLE ONLY _SURVEY__TEMPLATE_.raw_lines
--
ALTER TABLE ONLY _SURVEY__TEMPLATE_.raw_shots
ADD CONSTRAINT raw_shots_pkey PRIMARY KEY (sequence, point, class);
ADD CONSTRAINT raw_shots_pkey PRIMARY KEY (sequence, point);
--
@@ -739,7 +748,7 @@ ALTER TABLE ONLY _SURVEY__TEMPLATE_.raw_lines_files
--
ALTER TABLE ONLY _SURVEY__TEMPLATE_.raw_shots
ADD CONSTRAINT raw_shots_sequence_hash_fkey FOREIGN KEY (sequence, hash) REFERENCES _SURVEY__TEMPLATE_.raw_lines_files(sequence, hash) ON UPDATE CASCADE ON DELETE CASCADE;
ADD CONSTRAINT raw_shots_sequence_hash_fkey FOREIGN KEY (hash, sequence) REFERENCES _SURVEY__TEMPLATE_.raw_lines_files(hash, sequence) ON UPDATE CASCADE ON DELETE CASCADE;
--