mirror of
https://gitlab.com/wgp/dougal/software.git
synced 2025-12-06 11:17:08 +00:00
749 lines
24 KiB
PL/PgSQL
749 lines
24 KiB
PL/PgSQL
--
|
|
-- PostgreSQL database dump
|
|
--
|
|
|
|
-- Dumped from database version 11.7
|
|
-- Dumped by pg_dump version 12.2
|
|
|
|
SET statement_timeout = 0;
|
|
SET lock_timeout = 0;
|
|
SET idle_in_transaction_session_timeout = 0;
|
|
SET client_encoding = 'UTF8';
|
|
SET standard_conforming_strings = on;
|
|
SELECT pg_catalog.set_config('search_path', '', false);
|
|
SET check_function_bodies = false;
|
|
SET xmloption = content;
|
|
SET client_min_messages = warning;
|
|
SET row_security = off;
|
|
|
|
--
|
|
-- Name: _SURVEY__TEMPLATE_; Type: SCHEMA; Schema: -; Owner: postgres
|
|
--
|
|
|
|
CREATE SCHEMA _SURVEY__TEMPLATE_;
|
|
|
|
|
|
ALTER SCHEMA _SURVEY__TEMPLATE_ OWNER TO postgres;
|
|
|
|
--
|
|
-- Name: add_file(text, text); Type: PROCEDURE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
CREATE PROCEDURE _SURVEY__TEMPLATE_.add_file(path_in text, hash_in text)
|
|
LANGUAGE plpgsql
|
|
AS $$
|
|
BEGIN
|
|
LOOP
|
|
BEGIN
|
|
INSERT INTO files (path, hash)
|
|
VALUES (path_in, hash_in)
|
|
ON CONFLICT ON CONSTRAINT files_pkey DO UPDATE
|
|
SET path = EXCLUDED.path;
|
|
RETURN;
|
|
EXCEPTION
|
|
WHEN unique_violation THEN
|
|
DELETE FROM files WHERE files.path = path_in;
|
|
-- And loop
|
|
END;
|
|
END LOOP;
|
|
END;
|
|
$$;
|
|
|
|
|
|
ALTER PROCEDURE _SURVEY__TEMPLATE_.add_file(path_in text, hash_in text) OWNER TO postgres;
|
|
|
|
--
|
|
-- Name: PROCEDURE add_file(path_in text, hash_in text); Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
COMMENT ON PROCEDURE _SURVEY__TEMPLATE_.add_file(path_in text, hash_in text) IS 'Adds a new file to the survey.
|
|
|
|
If the hash matches that of an existing entry, update the path of that entry to point to the new path. We assume that the file has been renamed.
|
|
|
|
If the path matches that of an existing entry, delete that entry (which cascades) and insert the new one.';
|
|
|
|
|
|
--
|
|
-- Name: binning_parameters(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
CREATE FUNCTION _SURVEY__TEMPLATE_.binning_parameters() RETURNS json
|
|
LANGUAGE sql STABLE LEAKPROOF PARALLEL SAFE
|
|
AS $$
|
|
SELECT data->'binning' binning FROM _SURVEY__TEMPLATE_.file_data WHERE data->>'binning' IS NOT NULL LIMIT 1;
|
|
$$;
|
|
|
|
|
|
ALTER FUNCTION _SURVEY__TEMPLATE_.binning_parameters() OWNER TO postgres;
|
|
|
|
--
|
|
-- Name: FUNCTION binning_parameters(); Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
COMMENT ON FUNCTION _SURVEY__TEMPLATE_.binning_parameters() IS 'Returns this survey''s binning parameters.
|
|
|
|
This assumes that the user has imported the survey configuration file (*.yaml) via import_survey_config.py or similar.
|
|
|
|
The configuration file must contain a correctly populated "binning" property for this to work.
|
|
|
|
All values are returned as being of type "text" and need casting before use.
|
|
';
|
|
|
|
|
|
--
|
|
-- Name: to_binning_grid(public.geometry); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
CREATE FUNCTION _SURVEY__TEMPLATE_.to_binning_grid(geom public.geometry) RETURNS public.geometry
|
|
LANGUAGE plpgsql STABLE LEAKPROOF
|
|
AS $$DECLARE
|
|
bp json := _SURVEY__TEMPLATE_.binning_parameters();
|
|
theta numeric := (bp->>'theta')::numeric * pi() / 180;
|
|
I_inc numeric DEFAULT 1;
|
|
J_inc numeric DEFAULT 1;
|
|
I_width numeric := (bp->>'I_width')::numeric;
|
|
J_width numeric := (bp->>'J_width')::numeric;
|
|
|
|
a numeric := (I_inc/I_width) * cos(theta);
|
|
b numeric := (I_inc/I_width) * -sin(theta);
|
|
c numeric := (J_inc/J_width) * sin(theta);
|
|
d numeric := (J_inc/J_width) * cos(theta);
|
|
xoff numeric := (bp->'origin'->>'I')::numeric;
|
|
yoff numeric := (bp->'origin'->>'J')::numeric;
|
|
E0 numeric := (bp->'origin'->>'easting')::numeric;
|
|
N0 numeric := (bp->'origin'->>'northing')::numeric;
|
|
BEGIN
|
|
-- RAISE NOTICE 'Matrix: a: %, b: %, c: %, d: %, xoff: %, yoff: %', a, b, c, d, xoff, yoff;
|
|
RETURN ST_SetSRID(ST_Affine(ST_Translate(geom, -E0, -N0), a, b, c, d, xoff, yoff), 0);
|
|
END
|
|
$$;
|
|
|
|
|
|
ALTER FUNCTION _SURVEY__TEMPLATE_.to_binning_grid(geom public.geometry) OWNER TO postgres;
|
|
|
|
--
|
|
-- Name: FUNCTION to_binning_grid(geom public.geometry); Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
COMMENT ON FUNCTION _SURVEY__TEMPLATE_.to_binning_grid(geom public.geometry) IS 'Convenience version of to_binning_grid(geometry, json). It calls binning_parameters itself.
|
|
';
|
|
|
|
|
|
--
|
|
-- Name: to_binning_grid(public.geometry, json); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
CREATE FUNCTION _SURVEY__TEMPLATE_.to_binning_grid(geom public.geometry, bp json) RETURNS public.geometry
|
|
LANGUAGE plpgsql IMMUTABLE PARALLEL SAFE
|
|
AS $$DECLARE
|
|
-- bp json := _SURVEY__TEMPLATE_.binning_parameters();
|
|
theta numeric := (bp->>'theta')::numeric * pi() / 180;
|
|
I_inc numeric DEFAULT 1;
|
|
J_inc numeric DEFAULT 1;
|
|
I_width numeric := (bp->>'I_width')::numeric;
|
|
J_width numeric := (bp->>'J_width')::numeric;
|
|
|
|
a numeric := (I_inc/I_width) * cos(theta);
|
|
b numeric := (I_inc/I_width) * -sin(theta);
|
|
c numeric := (J_inc/J_width) * sin(theta);
|
|
d numeric := (J_inc/J_width) * cos(theta);
|
|
xoff numeric := (bp->'origin'->>'I')::numeric;
|
|
yoff numeric := (bp->'origin'->>'J')::numeric;
|
|
E0 numeric := (bp->'origin'->>'easting')::numeric;
|
|
N0 numeric := (bp->'origin'->>'northing')::numeric;
|
|
BEGIN
|
|
-- RAISE NOTICE 'Matrix: a: %, b: %, c: %, d: %, xoff: %, yoff: %', a, b, c, d, xoff, yoff;
|
|
RETURN ST_SetSRID(ST_Affine(ST_Translate(geom, -E0, -N0), a, b, c, d, xoff, yoff), 0);
|
|
END
|
|
$$;
|
|
|
|
|
|
ALTER FUNCTION _SURVEY__TEMPLATE_.to_binning_grid(geom public.geometry, bp json) OWNER TO postgres;
|
|
|
|
--
|
|
-- Name: FUNCTION to_binning_grid(geom public.geometry, bp json); Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
COMMENT ON FUNCTION _SURVEY__TEMPLATE_.to_binning_grid(geom public.geometry, bp json) IS 'Converts a geometry to a seismic bin grid reference system. The parameters of the bin grid are given in the second argument and are typically the output from the binning_parameters() function.
|
|
|
|
NOTE: The proper way of doing this would be to define an EngineeringCRS in the spatial_ref_sys table. See EPSG:6918 for an example (https://epsg.io/6918).
|
|
';
|
|
|
|
|
|
SET default_tablespace = '';
|
|
|
|
--
|
|
-- Name: file_data; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
CREATE TABLE _SURVEY__TEMPLATE_.file_data (
|
|
hash text NOT NULL,
|
|
data json NOT NULL
|
|
);
|
|
|
|
|
|
ALTER TABLE _SURVEY__TEMPLATE_.file_data OWNER TO postgres;
|
|
|
|
--
|
|
-- Name: files; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
CREATE TABLE _SURVEY__TEMPLATE_.files (
|
|
path text NOT NULL,
|
|
hash text NOT NULL
|
|
);
|
|
|
|
|
|
ALTER TABLE _SURVEY__TEMPLATE_.files OWNER TO postgres;
|
|
|
|
--
|
|
-- Name: TABLE files; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
COMMENT ON TABLE _SURVEY__TEMPLATE_.files IS 'The files table keeps track of where data comes from.
|
|
|
|
Each piece of information coming from a file (which is
|
|
the vast majority of the data here) is associated with
|
|
the corresponding file and its state at the time the
|
|
data was last read. Any changes to the file will cause
|
|
the "hash" column (which is stat output) to change and
|
|
should invalidate the old data. New data will be read in
|
|
and replace the old one if the paths are the same. In the
|
|
event of a file move or deletion, the old data will remain
|
|
in the database but not be accessible. A mechanism should
|
|
be provided to purge this old data at suitable intervals.
|
|
';
|
|
|
|
|
|
--
|
|
-- Name: final_lines; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
CREATE TABLE _SURVEY__TEMPLATE_.final_lines (
|
|
sequence integer NOT NULL,
|
|
line integer NOT NULL,
|
|
remarks text DEFAULT ''::text NOT NULL
|
|
);
|
|
|
|
|
|
ALTER TABLE _SURVEY__TEMPLATE_.final_lines OWNER TO postgres;
|
|
|
|
--
|
|
-- Name: final_lines_files; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
CREATE TABLE _SURVEY__TEMPLATE_.final_lines_files (
|
|
sequence integer NOT NULL,
|
|
hash text NOT NULL
|
|
);
|
|
|
|
|
|
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,
|
|
point integer NOT NULL,
|
|
class character(1) NOT NULL,
|
|
objref character(4) 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
|
|
--
|
|
|
|
CREATE VIEW _SURVEY__TEMPLATE_.final_lines_summary AS
|
|
WITH summary AS (
|
|
SELECT DISTINCT fs.sequence,
|
|
first_value(fs.point) OVER w AS fsp,
|
|
last_value(fs.point) OVER w AS lsp,
|
|
first_value(fs.tstamp) OVER w AS ts0,
|
|
last_value(fs.tstamp) OVER w AS ts1,
|
|
count(fs.point) OVER w AS num_points,
|
|
public.st_distance(first_value(fs.geometry) OVER w, last_value(fs.geometry) OVER w) AS length,
|
|
((public.st_azimuth(first_value(fs.geometry) OVER w, last_value(fs.geometry) OVER w) * (180)::double precision) / pi()) AS azimuth
|
|
FROM _SURVEY__TEMPLATE_.final_shots fs
|
|
WINDOW w AS (PARTITION BY fs.sequence ORDER BY fs.tstamp ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING)
|
|
)
|
|
SELECT fl.sequence,
|
|
fl.line,
|
|
s.fsp,
|
|
s.lsp,
|
|
s.ts0,
|
|
s.ts1,
|
|
(s.ts1 - s.ts0) AS duration,
|
|
s.num_points,
|
|
(( 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
|
|
FROM (summary s
|
|
JOIN _SURVEY__TEMPLATE_.final_lines fl USING (sequence));
|
|
|
|
|
|
ALTER TABLE _SURVEY__TEMPLATE_.final_lines_summary OWNER TO postgres;
|
|
|
|
--
|
|
-- Name: final_lines_summary_geometry; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
CREATE VIEW _SURVEY__TEMPLATE_.final_lines_summary_geometry AS
|
|
WITH g AS (
|
|
SELECT fs.sequence,
|
|
public.st_makeline(public.st_transform(fs.geometry, 4326) ORDER BY fs.tstamp) AS geometry
|
|
FROM (_SURVEY__TEMPLATE_.final_shots fs
|
|
JOIN _SURVEY__TEMPLATE_.final_lines_summary USING (sequence))
|
|
GROUP BY fs.sequence
|
|
)
|
|
SELECT fls.sequence,
|
|
fls.line,
|
|
fls.fsp,
|
|
fls.lsp,
|
|
fls.ts0,
|
|
fls.ts1,
|
|
fls.duration,
|
|
fls.num_points,
|
|
fls.missing_shots,
|
|
fls.length,
|
|
fls.azimuth,
|
|
fls.remarks,
|
|
g.geometry
|
|
FROM (_SURVEY__TEMPLATE_.final_lines_summary fls
|
|
JOIN g USING (sequence));
|
|
|
|
|
|
ALTER TABLE _SURVEY__TEMPLATE_.final_lines_summary_geometry OWNER TO postgres;
|
|
|
|
--
|
|
-- Name: info; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
CREATE TABLE _SURVEY__TEMPLATE_.info (
|
|
key text NOT NULL,
|
|
value text
|
|
);
|
|
|
|
|
|
ALTER TABLE _SURVEY__TEMPLATE_.info OWNER TO postgres;
|
|
|
|
--
|
|
-- Name: preplot_lines; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
CREATE TABLE _SURVEY__TEMPLATE_.preplot_lines (
|
|
line integer NOT NULL,
|
|
class character(1) NOT NULL,
|
|
incr boolean DEFAULT true NOT NULL,
|
|
remarks text NOT NULL,
|
|
geometry public.geometry(LineString,_EPSG__CODE_) NOT NULL,
|
|
hash text NOT NULL
|
|
);
|
|
|
|
|
|
ALTER TABLE _SURVEY__TEMPLATE_.preplot_lines OWNER TO postgres;
|
|
|
|
--
|
|
-- Name: TABLE preplot_lines; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
COMMENT ON TABLE _SURVEY__TEMPLATE_.preplot_lines IS 'The preplot_lines table holds the vessel preplots for this project.
|
|
|
|
It is denormalised for convenience (length and azimuth attributes).
|
|
It also has a geometry column mean to hold a simplified representation
|
|
of each line. A LINESTRING can support crooked lines but it is up to
|
|
the higher levels of the application whether those would be used and/or
|
|
supported.
|
|
|
|
In theory, shot and receiver preplots could also be entered but those
|
|
are currently neither used nor supported by the application. If adding
|
|
support for them, it is likely that an additional column will be necessary
|
|
indicating the preplot type.
|
|
';
|
|
|
|
|
|
--
|
|
-- Name: preplot_lines_summary; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
CREATE VIEW _SURVEY__TEMPLATE_.preplot_lines_summary AS
|
|
WITH summary AS (
|
|
SELECT DISTINCT pp.line,
|
|
first_value(pp.point) OVER w AS p0,
|
|
last_value(pp.point) OVER w AS p1,
|
|
count(pp.point) OVER w AS num_points,
|
|
public.st_distance(first_value(pp.geometry) OVER w, last_value(pp.geometry) OVER w) AS length,
|
|
((public.st_azimuth(first_value(pp.geometry) OVER w, last_value(pp.geometry) OVER w) * (180)::double precision) / pi()) AS azimuth0,
|
|
((public.st_azimuth(last_value(pp.geometry) OVER w, first_value(pp.geometry) OVER w) * (180)::double precision) / pi()) AS azimuth1
|
|
FROM _SURVEY__TEMPLATE_.preplot_points pp
|
|
WHERE (pp.class = 'V'::bpchar)
|
|
WINDOW w AS (PARTITION BY pp.line ORDER BY pp.point ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING)
|
|
)
|
|
SELECT pl.line,
|
|
CASE
|
|
WHEN pl.incr THEN s.p0
|
|
ELSE s.p1
|
|
END AS fsp,
|
|
CASE
|
|
WHEN pl.incr THEN s.p1
|
|
ELSE s.p0
|
|
END AS lsp,
|
|
s.num_points,
|
|
s.length,
|
|
CASE
|
|
WHEN pl.incr THEN s.azimuth0
|
|
ELSE s.azimuth1
|
|
END AS azimuth,
|
|
pl.incr,
|
|
pl.remarks
|
|
FROM (summary s
|
|
JOIN _SURVEY__TEMPLATE_.preplot_lines pl ON (((pl.class = 'V'::bpchar) AND (s.line = pl.line))))
|
|
ORDER BY
|
|
CASE
|
|
WHEN pl.incr THEN s.p0
|
|
ELSE s.p1
|
|
END;
|
|
|
|
|
|
ALTER TABLE _SURVEY__TEMPLATE_.preplot_lines_summary OWNER TO postgres;
|
|
|
|
--
|
|
-- 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
|
|
--
|
|
|
|
CREATE TABLE _SURVEY__TEMPLATE_.raw_lines_files (
|
|
sequence integer NOT NULL,
|
|
hash text NOT NULL
|
|
);
|
|
|
|
|
|
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,
|
|
point integer NOT NULL,
|
|
class character(1) NOT NULL,
|
|
objref character(4) 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_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,
|
|
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))
|
|
), 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.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
|
|
FROM shot_data sd,
|
|
bin;
|
|
|
|
|
|
ALTER TABLE _SURVEY__TEMPLATE_.raw_shots_ij_error OWNER TO postgres;
|
|
|
|
--
|
|
-- Name: shot_count; Type: VIEW; 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;
|
|
|
|
|
|
ALTER TABLE _SURVEY__TEMPLATE_.shot_count OWNER TO postgres;
|
|
|
|
--
|
|
-- Name: file_data file_data_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
ALTER TABLE ONLY _SURVEY__TEMPLATE_.file_data
|
|
ADD CONSTRAINT file_data_pkey PRIMARY KEY (hash);
|
|
|
|
|
|
--
|
|
-- Name: files files_path_key; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
ALTER TABLE ONLY _SURVEY__TEMPLATE_.files
|
|
ADD CONSTRAINT files_path_key UNIQUE (path);
|
|
|
|
|
|
--
|
|
-- Name: files files_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
ALTER TABLE ONLY _SURVEY__TEMPLATE_.files
|
|
ADD CONSTRAINT files_pkey PRIMARY KEY (hash);
|
|
|
|
|
|
--
|
|
-- Name: final_lines_files final_lines_files_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
ALTER TABLE ONLY _SURVEY__TEMPLATE_.final_lines_files
|
|
ADD CONSTRAINT final_lines_files_pkey PRIMARY KEY (sequence, hash);
|
|
|
|
|
|
--
|
|
-- Name: final_lines final_lines_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
ALTER TABLE ONLY _SURVEY__TEMPLATE_.final_lines
|
|
ADD CONSTRAINT final_lines_pkey PRIMARY KEY (sequence);
|
|
|
|
|
|
--
|
|
-- Name: final_shots final_shots_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
ALTER TABLE ONLY _SURVEY__TEMPLATE_.final_shots
|
|
ADD CONSTRAINT final_shots_pkey PRIMARY KEY (sequence, point, class);
|
|
|
|
|
|
--
|
|
-- Name: info info_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
ALTER TABLE ONLY _SURVEY__TEMPLATE_.info
|
|
ADD CONSTRAINT info_pkey PRIMARY KEY (key);
|
|
|
|
|
|
--
|
|
-- Name: preplot_lines preplot_lines_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
ALTER TABLE ONLY _SURVEY__TEMPLATE_.preplot_lines
|
|
ADD CONSTRAINT preplot_lines_pkey PRIMARY KEY (line, class);
|
|
|
|
|
|
--
|
|
-- Name: preplot_points preplot_points_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
ALTER TABLE ONLY _SURVEY__TEMPLATE_.preplot_points
|
|
ADD CONSTRAINT preplot_points_pkey PRIMARY KEY (line, point, class);
|
|
|
|
|
|
--
|
|
-- Name: raw_lines_files raw_lines_files_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
ALTER TABLE ONLY _SURVEY__TEMPLATE_.raw_lines_files
|
|
ADD CONSTRAINT raw_lines_files_pkey PRIMARY KEY (sequence, hash);
|
|
|
|
|
|
--
|
|
-- Name: raw_lines raw_lines_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
ALTER TABLE ONLY _SURVEY__TEMPLATE_.raw_lines
|
|
ADD CONSTRAINT raw_lines_pkey PRIMARY KEY (sequence);
|
|
|
|
|
|
--
|
|
-- Name: raw_shots raw_shots_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
ALTER TABLE ONLY _SURVEY__TEMPLATE_.raw_shots
|
|
ADD CONSTRAINT raw_shots_pkey PRIMARY KEY (sequence, point, class);
|
|
|
|
|
|
--
|
|
-- Name: file_data file_data_hash_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
ALTER TABLE ONLY _SURVEY__TEMPLATE_.file_data
|
|
ADD CONSTRAINT file_data_hash_fkey FOREIGN KEY (hash) REFERENCES _SURVEY__TEMPLATE_.files(hash) ON UPDATE CASCADE ON DELETE CASCADE;
|
|
|
|
|
|
--
|
|
-- Name: final_lines_files final_lines_files_hash_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
ALTER TABLE ONLY _SURVEY__TEMPLATE_.final_lines_files
|
|
ADD CONSTRAINT final_lines_files_hash_fkey FOREIGN KEY (hash) REFERENCES _SURVEY__TEMPLATE_.files(hash) ON UPDATE CASCADE ON DELETE CASCADE;
|
|
|
|
|
|
--
|
|
-- Name: final_lines_files final_lines_files_sequence_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
ALTER TABLE ONLY _SURVEY__TEMPLATE_.final_lines_files
|
|
ADD CONSTRAINT final_lines_files_sequence_fkey FOREIGN KEY (sequence) REFERENCES _SURVEY__TEMPLATE_.final_lines(sequence) ON UPDATE CASCADE ON DELETE CASCADE;
|
|
|
|
|
|
--
|
|
-- Name: final_shots final_shots_hash_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
ALTER TABLE ONLY _SURVEY__TEMPLATE_.final_shots
|
|
ADD CONSTRAINT final_shots_hash_fkey FOREIGN KEY (hash, sequence) REFERENCES _SURVEY__TEMPLATE_.final_lines_files(hash, sequence) ON UPDATE CASCADE ON DELETE CASCADE;
|
|
|
|
|
|
--
|
|
-- Name: preplot_lines preplot_lines_hash_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
ALTER TABLE ONLY _SURVEY__TEMPLATE_.preplot_lines
|
|
ADD CONSTRAINT preplot_lines_hash_fkey FOREIGN KEY (hash) REFERENCES _SURVEY__TEMPLATE_.files(hash) ON UPDATE CASCADE ON DELETE CASCADE;
|
|
|
|
|
|
--
|
|
-- Name: preplot_points preplot_points_line_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
ALTER TABLE ONLY _SURVEY__TEMPLATE_.preplot_points
|
|
ADD CONSTRAINT preplot_points_line_fkey FOREIGN KEY (line, class) REFERENCES _SURVEY__TEMPLATE_.preplot_lines(line, class) ON UPDATE CASCADE ON DELETE CASCADE;
|
|
|
|
|
|
--
|
|
-- Name: raw_lines_files raw_lines_files_hash_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
ALTER TABLE ONLY _SURVEY__TEMPLATE_.raw_lines_files
|
|
ADD CONSTRAINT raw_lines_files_hash_fkey FOREIGN KEY (hash) REFERENCES _SURVEY__TEMPLATE_.files(hash) ON UPDATE CASCADE ON DELETE CASCADE;
|
|
|
|
|
|
--
|
|
-- Name: raw_lines_files raw_lines_files_sequence_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
ALTER TABLE ONLY _SURVEY__TEMPLATE_.raw_lines_files
|
|
ADD CONSTRAINT raw_lines_files_sequence_fkey FOREIGN KEY (sequence) REFERENCES _SURVEY__TEMPLATE_.raw_lines(sequence) ON UPDATE CASCADE ON DELETE CASCADE;
|
|
|
|
|
|
--
|
|
-- Name: raw_shots raw_shots_sequence_hash_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
|
|
--
|
|
|
|
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;
|
|
|
|
|
|
--
|
|
-- PostgreSQL database dump complete
|
|
--
|
|
|