Files
dougal-software/etc/db/schema-template.sql
2020-09-06 14:49:42 +02:00

1442 lines
44 KiB
PL/PgSQL
Raw Blame History

This file contains ambiguous Unicode characters

This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.

--
-- PostgreSQL database dump
--
-- Dumped from database version 12.4
-- Dumped by pg_dump version 12.4
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 = '';
SET default_table_access_method = heap;
--
-- 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: 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_),
meta jsonb DEFAULT '{}'::jsonb NOT NULL
);
ALTER TABLE _SURVEY__TEMPLATE_.raw_shots OWNER TO postgres;
--
-- Name: events_midnight_shot; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_.events_midnight_shot AS
WITH t AS (
SELECT rs.sequence,
min(rs.tstamp) AS ts0,
max(rs.tstamp) AS ts1
FROM _SURVEY__TEMPLATE_.raw_shots rs
GROUP BY rs.sequence, (date(rs.tstamp))
), s AS (
SELECT t0.sequence,
t0.ts1,
t1.ts0
FROM (t t0
JOIN t t1 ON (((t0.sequence = t1.sequence) AND (date(t0.ts0) < date(t1.ts1)))))
)
SELECT rs.sequence,
rs.line,
rs.point,
rs.objref,
rs.tstamp,
rs.hash,
rs.geometry,
l.name AS label
FROM ((s
JOIN _SURVEY__TEMPLATE_.raw_shots rs ON ((rs.tstamp = s.ts1)))
JOIN _SURVEY__TEMPLATE_.labels l ON ((l.name = 'LDSP'::text)))
UNION ALL
SELECT rs.sequence,
rs.line,
rs.point,
rs.objref,
rs.tstamp,
rs.hash,
rs.geometry,
l.name AS label
FROM ((s
JOIN _SURVEY__TEMPLATE_.raw_shots rs ON ((rs.tstamp = s.ts0)))
JOIN _SURVEY__TEMPLATE_.labels l ON ((l.name = 'FDSP'::text)));
ALTER TABLE _SURVEY__TEMPLATE_.events_midnight_shot OWNER TO postgres;
--
-- Name: events_seq; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TABLE _SURVEY__TEMPLATE_.events_seq (
id serial NOT NULL,
remarks text NOT NULL,
sequence integer NOT NULL,
point integer NOT NULL,
meta jsonb DEFAULT '{}'::jsonb 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_timed; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_.events_seq_timed AS
SELECT s.sequence,
s.point,
s.id,
s.remarks,
rs.line,
rs.objref,
rs.tstamp,
rs.hash,
rs.geometry
FROM (_SURVEY__TEMPLATE_.events_seq s
LEFT JOIN _SURVEY__TEMPLATE_.raw_shots rs USING (sequence, point));
ALTER TABLE _SURVEY__TEMPLATE_.events_seq_timed OWNER TO postgres;
--
-- Name: events_timed; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TABLE _SURVEY__TEMPLATE_.events_timed (
id serial NOT NULL,
remarks text NOT NULL,
tstamp timestamp with time zone NOT NULL,
meta jsonb DEFAULT '{}'::jsonb NOT NULL
);
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: 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,
ntba boolean DEFAULT false NOT NULL,
geometry public.geometry(Point,_EPSG__CODE_) NOT NULL,
meta jsonb DEFAULT '{}'::jsonb 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: COLUMN preplot_points.ntba; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON COLUMN _SURVEY__TEMPLATE_.preplot_points.ntba IS 'Not to be acquired. A value of True causes this preplot not to be reported as a missed shot and not to be taken into account in completion stats.';
--
-- 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,
meta jsonb DEFAULT '{}'::jsonb NOT NULL
);
ALTER TABLE _SURVEY__TEMPLATE_.raw_lines 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,
rl.ntbp
FROM (summary s
JOIN _SURVEY__TEMPLATE_.raw_lines rl USING (sequence));
ALTER TABLE _SURVEY__TEMPLATE_.raw_lines_summary OWNER TO postgres;
--
-- Name: events_timed_seq; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_.events_timed_seq AS
WITH seqs AS (
SELECT e.id,
e.remarks,
e.tstamp,
rls.sequence,
rls.fsp,
rls.lsp,
rls.ts0,
rls.ts1
FROM (_SURVEY__TEMPLATE_.events_timed e
LEFT JOIN _SURVEY__TEMPLATE_.raw_lines_summary rls ON (((e.tstamp >= rls.ts0) AND (e.tstamp <= rls.ts1))))
)
SELECT seqs.sequence,
seqs.id,
seqs.remarks,
seqs.tstamp,
seqs.fsp,
seqs.lsp,
seqs.ts0,
seqs.ts1,
shots.line,
shots.point,
shots.objref,
shots.tstamp AS shot_tstamp,
shots.hash,
shots.geometry
FROM (seqs
LEFT JOIN LATERAL ( SELECT rs.sequence,
rs.line,
rs.point,
rs.objref,
rs.tstamp,
rs.hash,
rs.geometry
FROM _SURVEY__TEMPLATE_.raw_shots rs
ORDER BY (seqs.tstamp OPERATOR(public.<->) rs.tstamp)
LIMIT 1) shots USING (sequence));
ALTER TABLE _SURVEY__TEMPLATE_.events_timed_seq OWNER TO postgres;
--
-- Name: events; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_.events AS
SELECT 'sequence'::text AS type,
false AS virtual,
s.sequence,
s.point,
s.id,
s.remarks,
s.line,
s.objref,
s.tstamp,
s.hash,
s.geometry
FROM _SURVEY__TEMPLATE_.events_seq_timed s
UNION
SELECT 'timed'::text AS type,
false AS virtual,
t.sequence,
t.point,
t.id,
t.remarks,
t.line,
t.objref,
t.tstamp,
t.hash,
t.geometry
FROM _SURVEY__TEMPLATE_.events_timed_seq t
UNION
SELECT 'midnight shot'::text AS type,
true AS virtual,
v1.sequence,
v1.point,
((v1.sequence * 100000) + v1.point) AS id,
''::text AS remarks,
v1.line,
v1.objref,
v1.tstamp,
v1.hash,
v1.geometry
FROM _SURVEY__TEMPLATE_.events_midnight_shot v1;
ALTER TABLE _SURVEY__TEMPLATE_.events OWNER TO postgres;
--
-- 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_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: events_labels; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_.events_labels AS
SELECT 'timed'::text AS type,
events_timed_labels.id,
events_timed_labels.label
FROM _SURVEY__TEMPLATE_.events_timed_labels
UNION
SELECT 'sequence'::text AS type,
events_seq_labels.id,
events_seq_labels.label
FROM _SURVEY__TEMPLATE_.events_seq_labels
UNION
SELECT 'midnight shot'::text AS type,
((events_midnight_shot.sequence * 100000) + events_midnight_shot.point) AS id,
events_midnight_shot.label
FROM _SURVEY__TEMPLATE_.events_midnight_shot;
ALTER TABLE _SURVEY__TEMPLATE_.events_labels 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: 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,
meta jsonb DEFAULT '{}'::jsonb NOT NULL
);
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 form—or 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
--
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,
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_),
meta jsonb DEFAULT '{}'::jsonb NOT NULL
);
ALTER TABLE _SURVEY__TEMPLATE_.final_shots OWNER TO postgres;
--
-- 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: 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: 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
--
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,
ntba boolean DEFAULT false NOT NULL,
geometry public.geometry(LineString,_EPSG__CODE_) NOT NULL,
hash text NOT NULL,
meta jsonb DEFAULT '{}'::jsonb 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: COLUMN preplot_lines.ntba; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON COLUMN _SURVEY__TEMPLATE_.preplot_lines.ntba IS 'Not to be acquired. A value of True causes this preplot not to be reported as a missed shot and not to be taken into account in completion stats.';
--
-- 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: 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: 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
--
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_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
--
CREATE VIEW _SURVEY__TEMPLATE_.raw_shots_ij_error AS
WITH shot_data AS (
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 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.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_.raw_shots_ij_error OWNER TO postgres;
--
-- Name: VIEW raw_shots_ij_error; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: 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
--
CREATE VIEW _SURVEY__TEMPLATE_.sequences_summary AS
SELECT rls.sequence,
rls.line,
rls.fsp,
rls.lsp,
fls.fsp AS fsp_final,
fls.lsp AS lsp_final,
rls.ts0,
rls.ts1,
fls.ts0 AS ts0_final,
fls.ts1 AS ts1_final,
rls.duration,
fls.duration AS duration_final,
rls.num_preplots,
COALESCE(fls.num_points, rls.num_points) AS num_points,
COALESCE(fls.missing_shots, rls.missing_shots) AS missing_shots,
COALESCE(fls.length, rls.length) AS length,
COALESCE(fls.azimuth, rls.azimuth) AS azimuth,
rls.remarks,
fls.remarks AS remarks_final,
CASE
WHEN (rls.ntbp IS TRUE) THEN 'ntbp'::text
WHEN (fls.sequence IS NULL) THEN 'raw'::text
ELSE 'final'::text
END AS status
FROM (_SURVEY__TEMPLATE_.raw_lines_summary rls
LEFT JOIN _SURVEY__TEMPLATE_.final_lines_summary fls USING (sequence));
ALTER TABLE _SURVEY__TEMPLATE_.sequences_summary OWNER TO postgres;
--
-- 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_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
--
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);
--
-- 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: 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
--
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);
--
-- 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 (tstamp);
--
-- 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) ON UPDATE CASCADE ON DELETE CASCADE;
--
-- 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_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
--
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 (hash, sequence) REFERENCES _SURVEY__TEMPLATE_.raw_lines_files(hash, sequence) ON UPDATE CASCADE ON DELETE CASCADE;
--
-- PostgreSQL database dump complete
--