2020-08-08 23:59:13 +02:00
--
-- PostgreSQL database dump
--
2022-05-01 19:47:16 +02:00
-- Dumped from database version 14.2
-- Dumped by pg_dump version 14.2
2020-08-08 23:59:13 +02:00
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
--
2022-03-15 14:17:28 +01:00
CREATE PROCEDURE _SURVEY__TEMPLATE_ . add_file ( IN path_in text , IN hash_in text )
2020-08-08 23:59:13 +02:00
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 ;
$ $ ;
2022-03-15 14:17:28 +01:00
ALTER PROCEDURE _SURVEY__TEMPLATE_ . add_file ( IN path_in text , IN hash_in text ) OWNER TO postgres ;
2020-08-08 23:59:13 +02:00
--
2022-03-15 14:17:28 +01:00
-- Name: PROCEDURE add_file(IN path_in text, IN hash_in text); Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
2020-08-08 23:59:13 +02:00
--
2022-03-15 14:17:28 +01:00
COMMENT ON PROCEDURE _SURVEY__TEMPLATE_ . add_file ( IN path_in text , IN hash_in text ) IS ' Adds a new file to the survey.
2020-08-08 23:59:13 +02:00
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 . ' ;
2021-06-19 12:18:28 +02:00
--
-- Name: adjust_planner(); Type: PROCEDURE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE PROCEDURE _SURVEY__TEMPLATE_ . adjust_planner ( )
LANGUAGE plpgsql
AS $ $
DECLARE
_planner_config jsonb ;
_planned_line planned_lines % ROWTYPE ;
_lag interval ;
_last_sequence sequences_summary % ROWTYPE ;
_deltatime interval ;
_shotinterval interval ;
_tstamp timestamptz ;
_incr integer ;
BEGIN
SET CONSTRAINTS planned_lines_pkey DEFERRED ;
SELECT data - > ' planner '
INTO _planner_config
FROM file_data
WHERE data ? ' planner ' ;
SELECT *
INTO _last_sequence
FROM sequences_summary
ORDER BY sequence DESC
LIMIT 1 ;
SELECT *
INTO _planned_line
FROM planned_lines
WHERE sequence = _last_sequence . sequence AND line = _last_sequence . line ;
2022-03-15 14:17:28 +01:00
2021-06-19 12:18:28 +02:00
SELECT
COALESCE (
( ( lead ( ts0 ) OVER ( ORDER BY sequence ) ) - ts1 ) ,
make_interval ( mins = > ( _planner_config - > > ' defaultLineChangeDuration ' ) : : integer )
)
INTO _lag
FROM planned_lines
WHERE sequence = _last_sequence . sequence AND line = _last_sequence . line ;
2022-03-15 14:17:28 +01:00
2021-06-19 12:18:28 +02:00
_incr = sign ( _last_sequence . lsp - _last_sequence . fsp ) ;
2022-03-15 14:17:28 +01:00
2021-06-19 12:18:28 +02:00
RAISE NOTICE ' _planner_config: % ' , _planner_config ;
RAISE NOTICE ' _last_sequence: % ' , _last_sequence ;
RAISE NOTICE ' _planned_line: % ' , _planned_line ;
RAISE NOTICE ' _incr: % ' , _incr ;
2022-03-15 14:17:28 +01:00
2021-06-19 12:18:28 +02:00
-- Does the latest sequence match a planned sequence?
IF _planned_line IS NULL THEN -- No it doesn't
RAISE NOTICE ' Latest sequence shot does not match a planned sequence ' ;
SELECT * INTO _planned_line FROM planned_lines ORDER BY sequence ASC LIMIT 1 ;
RAISE NOTICE ' _planned_line: % ' , _planned_line ;
2022-03-15 14:17:28 +01:00
2021-06-19 12:18:28 +02:00
IF _planned_line . sequence < = _last_sequence . sequence THEN
RAISE NOTICE ' Renumbering the planned sequences starting from % ' , _planned_line . sequence + 1 ;
-- Renumber the planned sequences starting from last shot sequence number + 1
UPDATE planned_lines
SET sequence = sequence + _last_sequence . sequence - _planned_line . sequence + 1 ;
END IF ;
2022-03-15 14:17:28 +01:00
2021-06-19 12:18:28 +02:00
-- The correction to make to the first planned line's ts0 will be based on either the last
-- sequence's EOL + default line change time or the current time, whichever is later.
_deltatime : = GREATEST ( COALESCE ( _last_sequence . ts1_final , _last_sequence . ts1 ) + make_interval ( mins = > ( _planner_config - > > ' defaultLineChangeDuration ' ) : : integer ) , current_timestamp ) - _planned_line . ts0 ;
2022-03-15 14:17:28 +01:00
2021-06-19 12:18:28 +02:00
-- Is the first of the planned lines start time in the past? (±5 mins)
IF _planned_line . ts0 < ( current_timestamp - make_interval ( mins = > 5 ) ) THEN
RAISE NOTICE ' First planned line is in the past. Adjusting times by % ' , _deltatime ;
-- Adjust the start / end time of the planned lines by assuming that we are at
-- `defaultLineChangeDuration` minutes away from SOL of the first planned line.
UPDATE planned_lines
SET
ts0 = ts0 + _deltatime ,
ts1 = ts1 + _deltatime ;
END IF ;
2022-03-15 14:17:28 +01:00
2021-06-19 12:18:28 +02:00
ELSE -- Yes it does
RAISE NOTICE ' Latest sequence does match a planned sequence: %, % ' , _planned_line . sequence , _planned_line . line ;
2022-03-15 14:17:28 +01:00
2021-06-19 12:18:28 +02:00
-- Is it online?
IF EXISTS ( SELECT 1 FROM raw_lines_files WHERE sequence = _last_sequence . sequence AND hash = ' *online* ' ) THEN
-- Yes it is
RAISE NOTICE ' Sequence % is online ' , _last_sequence . sequence ;
2022-03-15 14:17:28 +01:00
2021-06-19 12:18:28 +02:00
-- Let us get the SOL from the events log if we can
RAISE NOTICE ' Trying to set fsp, ts0 from events log FSP, FGSP ' ;
WITH e AS (
SELECT * FROM events
WHERE
sequence = _last_sequence . sequence
AND ( ' FSP ' = ANY ( labels ) OR ' FGSP ' = ANY ( labels ) )
ORDER BY tstamp LIMIT 1
)
UPDATE planned_lines
SET
fsp = COALESCE ( e . point , fsp ) ,
ts0 = COALESCE ( e . tstamp , ts0 )
FROM e
WHERE planned_lines . sequence = _last_sequence . sequence ;
2022-03-15 14:17:28 +01:00
2021-06-19 12:18:28 +02:00
-- Shot interval
_shotinterval : = ( _last_sequence . ts1 - _last_sequence . ts0 ) / abs ( _last_sequence . lsp - _last_sequence . fsp ) ;
2022-03-15 14:17:28 +01:00
2021-06-19 12:18:28 +02:00
RAISE NOTICE ' Estimating EOL from current shot interval: % ' , _shotinterval ;
2022-03-15 14:17:28 +01:00
2021-06-19 12:18:28 +02:00
SELECT ( abs ( lsp - fsp ) * _shotinterval + ts0 ) - ts1
INTO _deltatime
FROM planned_lines
WHERE sequence = _last_sequence . sequence ;
- - -- Set ts1 for the current sequence
- - UPDATE planned_lines
- - SET
- - ts1 = ( abs ( lsp - fsp ) * _shotinterval ) + ts0
- - WHERE sequence = _last_sequence . sequence ;
2022-03-15 14:17:28 +01:00
2021-06-19 12:18:28 +02:00
RAISE NOTICE ' Adjustment is % ' , _deltatime ;
2022-03-15 14:17:28 +01:00
IF abs ( EXTRACT ( EPOCH FROM _deltatime ) ) < 8 THEN
2021-06-19 12:18:28 +02:00
RAISE NOTICE ' Adjustment too small (< 8 s), so not applying it ' ;
RETURN ;
END IF ;
-- Adjust ts1 for the current sequence
UPDATE planned_lines
SET ts1 = ts1 + _deltatime
WHERE sequence = _last_sequence . sequence ;
2022-03-15 14:17:28 +01:00
2021-06-19 12:18:28 +02:00
-- Now shift all sequences after
UPDATE planned_lines
SET ts0 = ts0 + _deltatime , ts1 = ts1 + _deltatime
WHERE sequence > _last_sequence . sequence ;
RAISE NOTICE ' Deleting planned sequences before % ' , _planned_line . sequence ;
-- Remove all previous planner entries.
DELETE
FROM planned_lines
WHERE sequence < _last_sequence . sequence ;
2022-03-15 14:17:28 +01:00
2021-06-19 12:18:28 +02:00
ELSE
-- No it isn't
RAISE NOTICE ' Sequence % is offline ' , _last_sequence . sequence ;
2022-03-15 14:17:28 +01:00
2021-06-19 12:18:28 +02:00
-- We were supposed to finish at _planned_line.ts1 but we finished at:
_tstamp : = GREATEST ( COALESCE ( _last_sequence . ts1_final , _last_sequence . ts1 ) , current_timestamp ) ;
-- WARNING Next line is for testing only
- - _tstamp : = COALESCE ( _last_sequence . ts1_final , _last_sequence . ts1 ) ;
-- So we need to adjust timestamps by:
_deltatime : = _tstamp - _planned_line . ts1 ;
RAISE NOTICE ' Planned end: %, actual end: % (%, %) ' , _planned_line . ts1 , _tstamp , _planned_line . sequence , _last_sequence . sequence ;
RAISE NOTICE ' Shifting times by % for sequences > % ' , _deltatime , _planned_line . sequence ;
-- NOTE: This won't work if sequences are not, err… sequential.
-- NOTE: This has been known to happen in 2020.
UPDATE planned_lines
SET
ts0 = ts0 + _deltatime ,
ts1 = ts1 + _deltatime
WHERE sequence > _planned_line . sequence ;
2022-03-15 14:17:28 +01:00
2021-06-19 12:18:28 +02:00
RAISE NOTICE ' Deleting planned sequences up to % ' , _planned_line . sequence ;
-- Remove all previous planner entries.
DELETE
FROM planned_lines
WHERE sequence < = _last_sequence . sequence ;
2022-03-15 14:17:28 +01:00
2021-06-19 12:18:28 +02:00
END IF ;
2022-03-15 14:17:28 +01:00
2021-06-19 12:18:28 +02:00
END IF ;
END ;
$ $ ;
ALTER PROCEDURE _SURVEY__TEMPLATE_ . adjust_planner ( ) OWNER TO postgres ;
2020-09-30 22:45:50 +02:00
--
-- Name: assoc_tstamp(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE FUNCTION _SURVEY__TEMPLATE_ . assoc_tstamp ( ) RETURNS trigger
LANGUAGE plpgsql
AS $ $
DECLARE
geom jsonb ;
BEGIN
IF NOT ( NEW . meta ? ' geometry ' ) THEN
-- Get the geometry from the real time event
-- closest in time and not more than one minute
-- away.
SELECT geometry : : jsonb
INTO geom
FROM real_time_inputs rti
WHERE rti . tstamp < - > NEW . tstamp < interval ' 1 minute '
ORDER BY rti . tstamp < - > NEW . tstamp
LIMIT 1 ;
IF geom IS NOT NULL THEN
NEW . meta : = jsonb_set ( NEW . meta , ' {geometry} ' , geom ) ;
END IF ;
END IF ;
RETURN NEW ;
END ;
$ $ ;
ALTER FUNCTION _SURVEY__TEMPLATE_ . assoc_tstamp ( ) OWNER TO postgres ;
2022-05-01 19:47:16 +02:00
--
-- Name: augment_event_data(); Type: PROCEDURE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE PROCEDURE _SURVEY__TEMPLATE_ . augment_event_data ( )
LANGUAGE sql
AS $ $
-- Populate the timestamp of sequence / point events
UPDATE event_log_full
SET tstamp = tstamp_from_sequence_shot ( sequence , point )
WHERE
tstamp IS NULL AND sequence IS NOT NULL AND point IS NOT NULL ;
-- Populate the geometry of sequence / point events for which
-- there is raw_shots data.
UPDATE event_log_full
SET meta = meta | |
jsonb_build_object (
' geometry ' ,
(
SELECT st_transform ( geometry , 4326 ) : : jsonb
FROM raw_shots rs
WHERE rs . sequence = event_log_full . sequence AND rs . point = event_log_full . point
)
)
WHERE
sequence IS NOT NULL AND point IS NOT NULL AND
NOT meta ? ' geometry ' ;
-- Populate the geometry of time-based events
UPDATE event_log_full e
SET
meta = meta | | jsonb_build_object ( ' geometry ' ,
( SELECT st_transform ( g . geometry , 4326 ) : : jsonb
FROM geometry_from_tstamp ( e . tstamp , 3 ) g ) )
WHERE
tstamp IS NOT NULL AND
sequence IS NULL AND point IS NULL AND
NOT meta ? ' geometry ' ;
-- Get rid of null geometries
UPDATE event_log_full
SET
meta = meta - ' geometry '
WHERE
jsonb_typeof ( meta - > ' geometry ' ) = ' null ' ;
-- Simplify the GeoJSON when the CRS is EPSG:4326
UPDATE event_log_full
SET
meta = meta #- '{geometry, crs}'
WHERE
meta - > ' geometry ' - > ' crs ' - > ' properties ' - > > ' name ' = ' EPSG:4326 ' ;
$ $ ;
ALTER PROCEDURE _SURVEY__TEMPLATE_ . augment_event_data ( ) OWNER TO postgres ;
--
-- Name: PROCEDURE augment_event_data(); Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON PROCEDURE _SURVEY__TEMPLATE_ . augment_event_data ( ) IS ' Populate missing timestamps and geometries in event_log_full ' ;
2020-08-08 23:59:13 +02:00
--
-- Name: binning_parameters(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
2020-10-04 05:13:17 +02:00
CREATE FUNCTION _SURVEY__TEMPLATE_ . binning_parameters ( ) RETURNS jsonb
2020-08-08 23:59:13 +02:00
LANGUAGE sql STABLE LEAKPROOF PARALLEL SAFE
AS $ $
2020-10-04 05:13:17 +02:00
SELECT data - > ' binning ' binning FROM file_data WHERE data - > > ' binning ' IS NOT NULL LIMIT 1 ;
2020-08-08 23:59:13 +02:00
$ $ ;
ALTER FUNCTION _SURVEY__TEMPLATE_ . binning_parameters ( ) OWNER TO postgres ;
2020-10-02 17:30:42 +02:00
--
-- Name: clear_shot_qc(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE FUNCTION _SURVEY__TEMPLATE_ . clear_shot_qc ( ) RETURNS trigger
LANGUAGE plpgsql
AS $ $
DECLARE
pid text ;
BEGIN
-- Bail out early if there are no actual changes
IF TG_OP = ' UPDATE ' AND NOT ( NEW . * IS DISTINCT FROM OLD . * ) THEN
RETURN NULL ;
END IF ;
UPDATE raw_shots
SET meta = meta #- '{qc}'
WHERE ( sequence = NEW . sequence OR sequence = OLD . sequence )
AND ( point = NEW . point OR point = OLD . point ) ;
RETURN NULL ;
END ;
$ $ ;
ALTER FUNCTION _SURVEY__TEMPLATE_ . clear_shot_qc ( ) OWNER TO postgres ;
2022-03-15 14:17:28 +01:00
--
-- Name: event_log_full_insert(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE FUNCTION _SURVEY__TEMPLATE_ . event_log_full_insert ( ) RETURNS trigger
LANGUAGE plpgsql
AS $ $
BEGIN
NEW . id : = COALESCE ( NEW . id , NEW . uid ) ;
NEW . validity : = tstzrange ( current_timestamp , NULL ) ;
NEW . meta = COALESCE ( NEW . meta , ' {} ' : : jsonb ) ;
NEW . labels = COALESCE ( NEW . labels , ARRAY [ ] : : text [ ] ) ;
IF cardinality ( NEW . labels ) > 0 THEN
-- Remove duplicates
SELECT array_agg ( DISTINCT elements )
INTO NEW . labels
FROM ( SELECT unnest ( NEW . labels ) AS elements ) AS labels ;
END IF ;
RETURN NEW ;
END ;
$ $ ;
ALTER FUNCTION _SURVEY__TEMPLATE_ . event_log_full_insert ( ) OWNER TO postgres ;
--
-- Name: event_log_update(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE FUNCTION _SURVEY__TEMPLATE_ . event_log_update ( ) RETURNS trigger
LANGUAGE plpgsql
AS $ $
BEGIN
IF ( TG_OP = ' INSERT ' ) THEN
-- Complete the tstamp if possible
IF NEW . sequence IS NOT NULL AND NEW . point IS NOT NULL AND NEW . tstamp IS NULL THEN
SELECT COALESCE (
tstamp_from_sequence_shot ( NEW . sequence , NEW . point ) ,
tstamp_interpolate ( NEW . sequence , NEW . point )
)
INTO NEW . tstamp ;
END IF ;
-- Any id that is provided will be ignored. The generated
-- id will match uid.
INSERT INTO event_log_full
( tstamp , sequence , point , remarks , labels , meta )
VALUES ( NEW . tstamp , NEW . sequence , NEW . point , NEW . remarks , NEW . labels , NEW . meta ) ;
RETURN NEW ;
ELSIF ( TG_OP = ' UPDATE ' ) THEN
-- Set end of validity and create a new entry with id
-- matching that of the old entry.
-- NOTE: Do not allow updating an event that has meta.readonly = true
IF EXISTS
( SELECT *
FROM event_log_full
WHERE id = OLD . id AND ( meta - > > ' readonly ' ) : : boolean IS TRUE )
THEN
RAISE check_violation USING MESSAGE = ' Cannot modify read-only entry ' ;
RETURN NULL ;
END IF ;
-- If the sequence / point has changed, and no new tstamp is provided, get one
IF NEW . sequence < > OLD . sequence OR NEW . point < > OLD . point
AND NEW . sequence IS NOT NULL AND NEW . point IS NOT NULL
AND NEW . tstamp IS NULL OR NEW . tstamp = OLD . tstamp THEN
SELECT COALESCE (
tstamp_from_sequence_shot ( NEW . sequence , NEW . point ) ,
tstamp_interpolate ( NEW . sequence , NEW . point )
)
INTO NEW . tstamp ;
END IF ;
UPDATE event_log_full
SET validity = tstzrange ( lower ( validity ) , current_timestamp )
WHERE validity @ > current_timestamp AND id = OLD . id ;
-- Any attempt to modify id will be ignored.
INSERT INTO event_log_full
( id , tstamp , sequence , point , remarks , labels , meta )
2022-04-27 17:41:53 +02:00
VALUES (
OLD . id ,
COALESCE ( NEW . tstamp , OLD . tstamp ) ,
COALESCE ( NEW . sequence , OLD . sequence ) ,
COALESCE ( NEW . point , OLD . point ) ,
COALESCE ( NEW . remarks , OLD . remarks ) ,
COALESCE ( NEW . labels , OLD . labels ) ,
COALESCE ( NEW . meta , OLD . meta )
) ;
2022-03-15 14:17:28 +01:00
RETURN NEW ;
ELSIF ( TG_OP = ' DELETE ' ) THEN
-- Set end of validity.
-- NOTE: We *do* allow deleting an event that has meta.readonly = true
-- This could be of interest if for instance we wanted to keep the history
-- of QC results for a point, provided that the QC routines write to
-- event_log and not event_log_full
UPDATE event_log_full
SET validity = tstzrange ( lower ( validity ) , current_timestamp )
WHERE validity @ > current_timestamp AND id = OLD . id ;
RETURN NULL ;
END IF ;
END ;
$ $ ;
ALTER FUNCTION _SURVEY__TEMPLATE_ . event_log_update ( ) OWNER TO postgres ;
2021-05-24 15:55:23 +02:00
--
-- Name: events_seq_labels_single(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE FUNCTION _SURVEY__TEMPLATE_ . events_seq_labels_single ( ) RETURNS trigger
LANGUAGE plpgsql
AS $ $
DECLARE _sequence integer ;
BEGIN
IF EXISTS ( SELECT 1 FROM labels WHERE name = NEW . label AND ( data - > ' model ' - > ' multiple ' ) : : boolean IS FALSE ) THEN
SELECT sequence INTO _sequence FROM events WHERE id = NEW . id ;
DELETE
FROM events_seq_labels
WHERE
id < > NEW . id
AND label = NEW . label
AND id IN ( SELECT id FROM events_seq WHERE sequence = _sequence ) ;
2022-03-15 14:17:28 +01:00
2021-05-24 15:55:23 +02:00
DELETE
FROM events_timed_labels
WHERE
id < > NEW . id
AND label = NEW . label
AND id IN ( SELECT id FROM events_timed_seq WHERE sequence = _sequence ) ;
END IF ;
RETURN NULL ;
END ;
$ $ ;
ALTER FUNCTION _SURVEY__TEMPLATE_ . events_seq_labels_single ( ) OWNER TO postgres ;
2020-09-14 23:54:48 +02:00
--
-- Name: events_timed_seq_match(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE FUNCTION _SURVEY__TEMPLATE_ . events_timed_seq_match ( ) RETURNS trigger
LANGUAGE plpgsql
AS $ $
BEGIN
IF EXISTS ( SELECT 1 FROM events_timed_seq WHERE id = NEW . id ) THEN
DELETE FROM events_timed_seq WHERE id = NEW . id ;
END IF ;
INSERT INTO events_timed_seq ( id , sequence , point )
( WITH seqs AS (
SELECT
e . id ,
e . tstamp ,
rls . sequence
FROM ( events_timed e
LEFT JOIN raw_lines_summary rls ON ( ( ( e . tstamp > = rls . ts0 ) AND ( e . tstamp < = rls . ts1 ) ) ) )
)
SELECT
seqs . id ,
seqs . sequence ,
shots . point
FROM ( seqs
LEFT JOIN LATERAL ( SELECT rs . sequence ,
rs . point
FROM raw_shots rs
ORDER BY ( seqs . tstamp OPERATOR ( public . < - > ) rs . tstamp )
LIMIT 1
) shots USING ( sequence ) )
WHERE seqs . id = NEW . id AND sequence IS NOT NULL AND point IS NOT NULL ) ;
RETURN NULL ;
END ;
$ $ ;
ALTER FUNCTION _SURVEY__TEMPLATE_ . events_timed_seq_match ( ) OWNER TO postgres ;
--
-- Name: events_timed_seq_update_all(); Type: PROCEDURE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE PROCEDURE _SURVEY__TEMPLATE_ . events_timed_seq_update_all ( )
LANGUAGE sql
AS $ $
TRUNCATE events_timed_seq ;
INSERT INTO events_timed_seq ( id , sequence , point )
( WITH seqs AS (
SELECT
e . id ,
e . tstamp ,
rls . sequence
FROM ( events_timed e
LEFT JOIN raw_lines_summary rls ON ( ( ( e . tstamp > = rls . ts0 ) AND ( e . tstamp < = rls . ts1 ) ) ) )
)
SELECT
seqs . id ,
seqs . sequence ,
shots . point
FROM ( seqs
LEFT JOIN LATERAL ( SELECT rs . sequence ,
rs . point
FROM raw_shots rs
ORDER BY ( seqs . tstamp OPERATOR ( public . < - > ) rs . tstamp )
LIMIT 1
) shots USING ( sequence ) )
WHERE seqs . id IS NOT NULL AND sequence IS NOT NULL AND point IS NOT NULL ) ;
$ $ ;
ALTER PROCEDURE _SURVEY__TEMPLATE_ . events_timed_seq_update_all ( ) OWNER TO postgres ;
2020-09-14 01:36:40 +02:00
--
2021-05-24 15:55:23 +02:00
-- Name: final_line_post_import(integer); Type: PROCEDURE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
2020-09-14 01:36:40 +02:00
--
2022-03-15 14:17:28 +01:00
CREATE PROCEDURE _SURVEY__TEMPLATE_ . final_line_post_import ( IN _seq integer )
2020-09-14 01:36:40 +02:00
LANGUAGE plpgsql
AS $ $
BEGIN
2020-08-08 23:59:13 +02:00
2021-05-24 15:55:23 +02:00
CALL handle_final_line_events ( _seq , ' FSP ' , ' fsp ' ) ;
CALL handle_final_line_events ( _seq , ' FGSP ' , ' fsp ' ) ;
CALL handle_final_line_events ( _seq , ' LGSP ' , ' lsp ' ) ;
CALL handle_final_line_events ( _seq , ' LSP ' , ' lsp ' ) ;
2020-10-04 05:13:17 +02:00
2021-05-24 15:55:23 +02:00
END ;
2020-08-08 23:59:13 +02:00
$ $ ;
2022-03-15 14:17:28 +01:00
ALTER PROCEDURE _SURVEY__TEMPLATE_ . final_line_post_import ( IN _seq integer ) OWNER TO postgres ;
2020-08-08 23:59:13 +02:00
--
2021-05-24 15:55:23 +02:00
-- Name: handle_final_line_events(integer, text, text); Type: PROCEDURE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
2020-08-08 23:59:13 +02:00
--
2022-03-15 14:17:28 +01:00
CREATE PROCEDURE _SURVEY__TEMPLATE_ . handle_final_line_events ( IN _seq integer , IN _label text , IN _column text )
2021-05-24 15:55:23 +02:00
LANGUAGE plpgsql
AS $ $
2020-10-04 05:13:17 +02:00
2021-05-24 15:55:23 +02:00
DECLARE
_line final_lines_summary % ROWTYPE ;
_column_value integer ;
_tg_name text : = ' final_line ' ;
2022-03-16 21:29:53 +01:00
_event event_log % ROWTYPE ;
2021-05-24 15:55:23 +02:00
event_id integer ;
2020-08-08 23:59:13 +02:00
BEGIN
2021-05-24 15:55:23 +02:00
SELECT * INTO _line FROM final_lines_summary WHERE sequence = _seq ;
_event : = label_in_sequence ( _seq , _label ) ;
_column_value : = row_to_json ( _line ) - > > _column ;
2022-03-15 14:17:28 +01:00
2021-05-24 15:55:23 +02:00
- - RAISE NOTICE ' % is % ' , _label , _event ;
- - RAISE NOTICE ' Line is % ' , _line ;
- - RAISE NOTICE ' % is % (%) ' , _column , _column_value , _label ;
2022-03-15 14:17:28 +01:00
2021-05-24 15:55:23 +02:00
IF _event IS NULL THEN
- - RAISE NOTICE ' We will populate the event log from the sequence data ' ;
2022-03-15 14:17:28 +01:00
2022-03-16 21:29:53 +01:00
INSERT INTO event_log ( sequence , point , remarks , labels , meta )
VALUES (
-- The sequence
_seq ,
-- The shotpoint
_column_value ,
-- Remark. Something like "FSP <linename>"
format ( ' %s %s ' , _label , ( SELECT meta - > > ' lineName ' FROM final_lines WHERE sequence = _seq ) ) ,
-- Label
ARRAY [ _label ] ,
-- Meta. Something like {"auto" : {"FSP" : "final_line"}}
json_build_object ( ' auto ' , json_build_object ( _label , _tg_name ) )
) ;
2022-03-15 14:17:28 +01:00
2021-05-24 15:55:23 +02:00
ELSE
- - RAISE NOTICE ' We may populate the sequence meta from the event log ' ;
- - RAISE NOTICE ' Unless the event log was populated by us previously ' ;
- - RAISE NOTICE ' Populated by us previously? % ' , _event . meta - > ' auto ' - > > _label = _tg_name ;
2022-03-15 14:17:28 +01:00
2021-05-24 15:55:23 +02:00
IF _event . meta - > ' auto ' - > > _label IS DISTINCT FROM _tg_name THEN
2022-03-16 21:29:53 +01:00
2021-05-24 15:55:23 +02:00
- - RAISE NOTICE ' Adding % found in events log to final_line meta ' , _label ;
UPDATE final_lines
SET meta = jsonb_set ( meta , ARRAY [ _label ] , to_jsonb ( _event . point ) )
WHERE sequence = _seq ;
2022-03-15 14:17:28 +01:00
2021-05-24 15:55:23 +02:00
END IF ;
2022-03-15 14:17:28 +01:00
2021-05-24 15:55:23 +02:00
END IF ;
END ;
2020-08-08 23:59:13 +02:00
$ $ ;
2022-03-15 14:17:28 +01:00
ALTER PROCEDURE _SURVEY__TEMPLATE_ . handle_final_line_events ( IN _seq integer , IN _label text , IN _column text ) OWNER TO postgres ;
2020-08-13 23:44:25 +02:00
--
2022-03-15 14:17:28 +01:00
-- Name: ij_error(double precision, double precision, public.geometry); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
2020-08-13 23:44:25 +02:00
--
2022-03-15 14:17:28 +01:00
CREATE FUNCTION _SURVEY__TEMPLATE_ . ij_error ( line double precision , point double precision , geom public . geometry ) RETURNS public . geometry
LANGUAGE plpgsql STABLE LEAKPROOF
2021-05-24 15:55:23 +02:00
AS $ $
2022-03-15 14:17:28 +01:00
DECLARE
bp jsonb : = binning_parameters ( ) ;
ij public . geometry : = to_binning_grid ( geom , bp ) ;
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 ;
error_i double precision ;
error_j double precision ;
2021-05-24 15:55:23 +02:00
BEGIN
2022-03-15 14:17:28 +01:00
error_i : = ( public . st_x ( ij ) - line ) * I_width ;
error_j : = ( public . st_y ( ij ) - point ) * J_width ;
RETURN public . ST_MakePoint ( error_i , error_j ) ;
END
2021-05-24 15:55:23 +02:00
$ $ ;
2022-03-15 14:17:28 +01:00
ALTER FUNCTION _SURVEY__TEMPLATE_ . ij_error ( line double precision , point double precision , geom public . geometry ) OWNER TO postgres ;
2021-05-24 15:55:23 +02:00
2022-03-16 21:29:53 +01:00
--
-- Name: event_log_uid_seq; Type: SEQUENCE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE SEQUENCE _SURVEY__TEMPLATE_ . event_log_uid_seq
AS integer
START WITH 1
INCREMENT BY 1
NO MINVALUE
NO MAXVALUE
CACHE 1 ;
ALTER TABLE _SURVEY__TEMPLATE_ . event_log_uid_seq OWNER TO postgres ;
SET default_tablespace = ' ' ;
SET default_table_access_method = heap ;
--
-- Name: event_log_full; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TABLE _SURVEY__TEMPLATE_ . event_log_full (
uid integer DEFAULT nextval ( ' _SURVEY__TEMPLATE_.event_log_uid_seq ' : : regclass ) NOT NULL ,
id integer NOT NULL ,
tstamp timestamp with time zone ,
sequence integer ,
point integer ,
remarks text DEFAULT ' ' : : text NOT NULL ,
labels text [ ] DEFAULT ARRAY [ ] : : text [ ] NOT NULL ,
meta jsonb DEFAULT ' {} ' : : jsonb NOT NULL ,
validity tstzrange NOT NULL ,
CONSTRAINT event_log_full_check CHECK ( ( ( ( tstamp IS NOT NULL ) AND ( sequence IS NOT NULL ) AND ( point IS NOT NULL ) ) OR ( ( tstamp IS NOT NULL ) AND ( sequence IS NULL ) AND ( point IS NULL ) ) OR ( ( tstamp IS NULL ) AND ( sequence IS NOT NULL ) AND ( point IS NOT NULL ) ) ) ) ,
CONSTRAINT event_log_full_validity_check CHECK ( ( NOT isempty ( validity ) ) )
) ;
ALTER TABLE _SURVEY__TEMPLATE_ . event_log_full OWNER TO postgres ;
--
-- Name: event_log; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_ . event_log AS
SELECT event_log_full . id ,
event_log_full . tstamp ,
event_log_full . sequence ,
event_log_full . point ,
event_log_full . remarks ,
event_log_full . labels ,
event_log_full . meta ,
( event_log_full . uid < > event_log_full . id ) AS has_edits ,
lower ( event_log_full . validity ) AS modified_on
FROM _SURVEY__TEMPLATE_ . event_log_full
WHERE ( event_log_full . validity @ > CURRENT_TIMESTAMP ) ;
ALTER TABLE _SURVEY__TEMPLATE_ . event_log OWNER TO postgres ;
--
-- Name: label_in_sequence(integer, text); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE FUNCTION _SURVEY__TEMPLATE_ . label_in_sequence ( _sequence integer , _label text ) RETURNS _SURVEY__TEMPLATE_ . event_log
LANGUAGE sql
AS $ $
SELECT * FROM event_log WHERE sequence = _sequence AND _label = ANY ( labels ) ;
$ $ ;
ALTER FUNCTION _SURVEY__TEMPLATE_ . label_in_sequence ( _sequence integer , _label text ) OWNER TO postgres ;
2021-05-24 15:55:23 +02:00
--
-- 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 jsonb : = 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: to_binning_grid(public.geometry, jsonb); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE FUNCTION _SURVEY__TEMPLATE_ . to_binning_grid ( geom public . geometry , bp jsonb ) RETURNS public . geometry
LANGUAGE plpgsql IMMUTABLE PARALLEL SAFE
AS $ $ DECLARE
-- bp jsonb := 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 jsonb ) OWNER TO postgres ;
2020-08-22 20:19:39 +02:00
--
2022-03-15 14:17:28 +01:00
-- Name: tstamp_from_sequence_shot(numeric, numeric); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
2020-08-22 20:19:39 +02:00
--
2022-03-15 14:17:28 +01:00
CREATE FUNCTION _SURVEY__TEMPLATE_ . tstamp_from_sequence_shot ( s numeric , p numeric , OUT ts timestamp with time zone ) RETURNS timestamp with time zone
LANGUAGE sql
AS $ $
SELECT tstamp FROM raw_shots WHERE sequence = s AND point = p LIMIT 1 ;
$ $ ;
2020-08-12 11:24:52 +02:00
2022-03-15 14:17:28 +01:00
ALTER FUNCTION _SURVEY__TEMPLATE_ . tstamp_from_sequence_shot ( s numeric , p numeric , OUT ts timestamp with time zone ) OWNER TO postgres ;
2020-08-12 11:24:52 +02:00
--
2022-03-15 14:17:28 +01:00
-- Name: FUNCTION tstamp_from_sequence_shot(s numeric, p numeric, OUT ts timestamp with time zone); Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
2020-08-12 11:24:52 +02:00
--
2022-03-15 14:17:28 +01:00
COMMENT ON FUNCTION _SURVEY__TEMPLATE_ . tstamp_from_sequence_shot ( s numeric , p numeric , OUT ts timestamp with time zone ) IS ' Get the timestamp of an existing shotpoint. ' ;
--
-- Name: tstamp_interpolate(numeric, numeric); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE FUNCTION _SURVEY__TEMPLATE_ . tstamp_interpolate ( s numeric , p numeric ) RETURNS timestamp with time zone
LANGUAGE plpgsql
AS $ $
DECLARE
ts0 timestamptz ;
ts1 timestamptz ;
pt0 numeric ;
pt1 numeric ;
BEGIN
SELECT tstamp , point
INTO ts0 , pt0
FROM raw_shots
WHERE sequence = s AND point < p
ORDER BY point DESC LIMIT 1 ;
SELECT tstamp , point
INTO ts1 , pt1
FROM raw_shots
WHERE sequence = s AND point > p
ORDER BY point ASC LIMIT 1 ;
2020-08-12 11:24:52 +02:00
2022-03-15 14:17:28 +01:00
RETURN ( ts1 - ts0 ) / abs ( pt1 - pt0 ) * abs ( p - pt0 ) + ts0 ;
2020-08-12 11:24:52 +02:00
2022-03-15 14:17:28 +01:00
END ;
$ $ ;
ALTER FUNCTION _SURVEY__TEMPLATE_ . tstamp_interpolate ( s numeric , p numeric ) OWNER TO postgres ;
2020-08-12 11:24:52 +02:00
--
2022-03-15 14:17:28 +01:00
-- Name: FUNCTION tstamp_interpolate(s numeric, p numeric); Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
2020-08-12 11:24:52 +02:00
--
2022-03-15 14:17:28 +01:00
COMMENT ON FUNCTION _SURVEY__TEMPLATE_ . tstamp_interpolate ( s numeric , p numeric ) IS ' Interpolate a timestamp given sequence and point values.
It will try to find the points immediately before and after in the sequence and interpolate into the gap , which may consist of multiple missed shots .
If called on an existing shotpoint it will return an interpolated timestamp as if the shotpoint did not exist , as opposed to returning its actual timestamp .
Returns NULL if it is not possible to interpolate . ' ;
2020-08-12 11:24:52 +02:00
--
-- Name: file_data; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TABLE _SURVEY__TEMPLATE_ . file_data (
hash text NOT NULL ,
2020-10-04 01:22:42 +02:00
data jsonb NOT NULL
2020-08-12 11:24:52 +02:00
) ;
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 ,
2020-09-06 13:37:11 +02:00
remarks text DEFAULT ' ' : : text NOT NULL ,
meta jsonb DEFAULT ' {} ' : : jsonb NOT NULL
2020-08-12 11:24:52 +02:00
) ;
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 ;
2020-08-22 20:19:39 +02:00
--
-- 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 ,
2020-09-06 13:37:11 +02:00
geometry public . geometry ( Point , _EPSG__CODE_ ) ,
meta jsonb DEFAULT ' {} ' : : jsonb NOT NULL
2020-08-22 20:19:39 +02:00
) ;
ALTER TABLE _SURVEY__TEMPLATE_ . final_shots OWNER TO postgres ;
2020-09-14 23:54:48 +02:00
--
-- 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. ' ;
2020-08-08 23:59:13 +02:00
--
-- 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 ,
2021-05-23 22:26:00 +02:00
fl . remarks ,
fl . meta
2020-08-08 23:59:13 +02:00
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 ;
2020-08-10 22:43:07 +02:00
--
-- 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 ;
2020-08-26 20:14:07 +02:00
--
-- 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 ;
2020-08-08 23:59:13 +02:00
--
-- Name: info; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TABLE _SURVEY__TEMPLATE_ . info (
key text NOT NULL ,
2020-09-10 20:49:39 +02:00
value jsonb
2020-08-08 23:59:13 +02:00
) ;
ALTER TABLE _SURVEY__TEMPLATE_ . info OWNER TO postgres ;
2022-03-15 14:17:28 +01:00
--
-- 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.) ' ;
2020-08-08 23:59:13 +02:00
--
-- 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 ,
2020-08-25 17:58:03 +02:00
ntba boolean DEFAULT false NOT NULL ,
2020-08-08 23:59:13 +02:00
geometry public . geometry ( LineString , _EPSG__CODE_ ) NOT NULL ,
2020-09-06 13:37:11 +02:00
hash text NOT NULL ,
meta jsonb DEFAULT ' {} ' : : jsonb NOT NULL
2020-08-08 23:59:13 +02:00
) ;
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 .
' ;
2020-08-25 17:58:03 +02:00
--
-- 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. ' ;
2020-10-04 03:33:23 +02:00
--
-- Name: preplot_saillines_points; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_ . preplot_saillines_points AS
WITH fdd AS (
SELECT pl . hash ,
pl . line ,
( ( pl . line ) : : numeric - ( ( fd . data - > ' saillineOffset ' : : text ) ) : : numeric ) AS l0 ,
( ( pl . line ) : : numeric + ( ( fd . data - > ' saillineOffset ' : : text ) ) : : numeric ) AS l1
FROM ( _SURVEY__TEMPLATE_ . preplot_lines pl
JOIN _SURVEY__TEMPLATE_ . file_data fd USING ( hash ) )
WHERE ( fd . data ? ' saillineOffset ' : : text )
)
SELECT plv . line AS sailline ,
plv . ntba AS sailline_ntba ,
pps . line ,
pps . point ,
pps . class ,
pps . ntba ,
pps . geometry ,
pps . meta
FROM ( ( fdd
JOIN _SURVEY__TEMPLATE_ . preplot_lines plv ON ( ( ( plv . class = ' V ' : : bpchar ) AND ( ( ( plv . line ) : : numeric = fdd . l0 ) OR ( ( plv . line ) : : numeric = fdd . l1 ) ) ) ) )
JOIN _SURVEY__TEMPLATE_ . preplot_points pps ON ( ( pps . line = fdd . line ) ) ) ;
ALTER TABLE _SURVEY__TEMPLATE_ . preplot_saillines_points OWNER TO postgres ;
--
-- Name: VIEW preplot_saillines_points; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON VIEW _SURVEY__TEMPLATE_ . preplot_saillines_points IS ' Associate source preplot lines with their corresponding sail lines.
This relies on the user having specified a " saillineOffset " value in
the import configuration for the associated preplot file . We then try
to match vessel lines by adding / subtracting this offset from our
source line numbers . It is substandard but it will do for the time
being . A better approach would be to explicitly import the sail lines ,
e . g . , by adding a column to the source preplots file . ' ;
2020-10-04 04:07:50 +02:00
--
-- 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 ;
2020-10-04 04:06:15 +02:00
--
-- Name: missing_final_points; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_ . missing_final_points AS
SELECT DISTINCT psp . sailline ,
psp . sailline_ntba ,
psp . line ,
psp . point ,
psp . class ,
psp . ntba ,
psp . geometry ,
psp . meta
FROM ( _SURVEY__TEMPLATE_ . preplot_saillines_points psp
LEFT JOIN ( ( _SURVEY__TEMPLATE_ . final_lines fl
JOIN _SURVEY__TEMPLATE_ . raw_lines rl ON ( ( ( fl . sequence = rl . sequence ) AND ( NOT rl . ntbp ) ) ) )
JOIN _SURVEY__TEMPLATE_ . final_shots fs ON ( ( fl . sequence = fs . sequence ) ) ) ON ( ( ( psp . sailline = fl . line ) AND ( psp . point = fs . point ) ) ) )
WHERE ( fl . sequence IS NULL ) ;
ALTER TABLE _SURVEY__TEMPLATE_ . missing_final_points OWNER TO postgres ;
--
-- Name: VIEW missing_final_points; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON VIEW _SURVEY__TEMPLATE_ . missing_final_points IS ' Return the set of points which have not yet been shot, or which have
been shot only in sequences which have subsequently been marked as
NTBP . Note that this includes lines and points which may have been
marked as NTBA ; we also return those but we report both the line
and point NTBA attributes ( via preplot_saillines_points . sailline_ntba
and preplot_saillines_points . ntba , respectively ) . ' ;
2020-10-04 03:33:23 +02:00
--
-- Name: missing_sequence_final_points; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_ . missing_sequence_final_points AS
WITH seqs AS (
SELECT fl . sequence ,
fl . line AS sailline ,
min ( fs_1 . point ) AS sp0 ,
max ( fs_1 . point ) AS sp1
FROM ( _SURVEY__TEMPLATE_ . final_lines fl
JOIN _SURVEY__TEMPLATE_ . final_shots fs_1 USING ( sequence ) )
GROUP BY fl . sequence , fl . line
)
SELECT seqs . sequence ,
psp . sailline ,
psp . sailline_ntba ,
psp . line ,
psp . point ,
psp . class ,
psp . ntba ,
psp . geometry ,
psp . meta
FROM ( ( _SURVEY__TEMPLATE_ . preplot_saillines_points psp
JOIN seqs USING ( sailline ) )
LEFT JOIN _SURVEY__TEMPLATE_ . final_shots fs USING ( sequence , point ) )
WHERE ( ( ( ( psp . point > = seqs . sp0 ) AND ( psp . point < = seqs . sp1 ) ) OR ( ( psp . point > = seqs . sp1 ) AND ( psp . point < = seqs . sp0 ) ) ) AND ( fs . * IS NULL ) ) ;
ALTER TABLE _SURVEY__TEMPLATE_ . missing_sequence_final_points OWNER TO postgres ;
--
-- Name: VIEW missing_sequence_final_points; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON VIEW _SURVEY__TEMPLATE_ . missing_sequence_final_points IS ' Return sequence missing shots. These are the shots that would typically
need to be reported as missing for a sequence . A point is missing from
a sequence if it is between the first and last shot for that sequence
but no final_shots point exists with that point number within that
sequence .
Note that the shot may not be missing from the overall production as it
might have been acquired in a later sequence .
Missing points are reported regardless of the underlying preplot NTBA
status . ' ;
2022-03-15 14:17:28 +01:00
--
-- 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 ;
2020-10-04 03:33:23 +02:00
--
-- Name: missing_sequence_raw_points; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_ . missing_sequence_raw_points AS
WITH seqs AS (
SELECT fl . sequence ,
fl . line AS sailline ,
min ( fs_1 . point ) AS sp0 ,
max ( fs_1 . point ) AS sp1
FROM ( _SURVEY__TEMPLATE_ . raw_lines fl
JOIN _SURVEY__TEMPLATE_ . raw_shots fs_1 USING ( sequence ) )
GROUP BY fl . sequence , fl . line
)
SELECT seqs . sequence ,
psp . sailline ,
psp . sailline_ntba ,
psp . line ,
psp . point ,
psp . class ,
psp . ntba ,
psp . geometry ,
psp . meta
FROM ( ( _SURVEY__TEMPLATE_ . preplot_saillines_points psp
JOIN seqs USING ( sailline ) )
LEFT JOIN _SURVEY__TEMPLATE_ . raw_shots fs USING ( sequence , point ) )
WHERE ( ( ( ( psp . point > = seqs . sp0 ) AND ( psp . point < = seqs . sp1 ) ) OR ( ( psp . point > = seqs . sp1 ) AND ( psp . point < = seqs . sp0 ) ) ) AND ( fs . * IS NULL ) ) ;
ALTER TABLE _SURVEY__TEMPLATE_ . missing_sequence_raw_points OWNER TO postgres ;
--
-- Name: VIEW missing_sequence_raw_points; Type: COMMENT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
COMMENT ON VIEW _SURVEY__TEMPLATE_ . missing_sequence_raw_points IS ' Return sequence missing raw shots. Analogous to missing_sequence_final_points,
refer to that view for more details . Note that the set of missing shots may not
coincide betwen raw and final data , due to edits on the final dataset . ' ;
2020-10-09 13:54:45 +02:00
--
-- Name: planned_lines; Type: TABLE; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TABLE _SURVEY__TEMPLATE_ . planned_lines (
sequence integer NOT NULL ,
line integer NOT NULL ,
fsp integer NOT NULL ,
lsp integer NOT NULL ,
ts0 timestamp with time zone NOT NULL ,
ts1 timestamp with time zone NOT NULL ,
name text NOT NULL ,
remarks text DEFAULT ' ' : : text NOT NULL ,
meta jsonb DEFAULT ' {} ' : : jsonb NOT NULL ,
class character ( 1 ) DEFAULT ' V ' : : bpchar NOT NULL
) ;
ALTER TABLE _SURVEY__TEMPLATE_ . planned_lines OWNER TO postgres ;
--
-- Name: planned_lines_summary; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_ . planned_lines_summary AS
SELECT pl . sequence ,
pl . line ,
pl . fsp ,
pl . lsp ,
pl . ts0 ,
pl . ts1 ,
pl . name ,
pl . remarks ,
pl . meta ,
pl . class ,
( SELECT count ( * ) AS count
FROM _SURVEY__TEMPLATE_ . preplot_points pp_1
WHERE ( ( pp_1 . line = pl . line ) AND ( pp_1 . class = pl . class ) AND ( ( ( pp_1 . point > = pl . fsp ) AND ( pp_1 . point < = pl . lsp ) ) OR ( ( pp_1 . point > = pl . lsp ) AND ( pp_1 . point < = pl . fsp ) ) ) ) ) AS num_points ,
( pl . ts1 - pl . ts0 ) AS duration ,
public . st_distance ( pp0 . geometry , pp1 . geometry ) AS length ,
( ( public . st_azimuth ( pp0 . geometry , pp1 . geometry ) * ( 180 . 0 ) : : double precision ) / pi ( ) ) AS azimuth ,
( public . st_transform ( public . st_makeline ( pp0 . geometry , pp1 . geometry ) , 4326 ) ) : : jsonb AS geometry
FROM ( ( ( _SURVEY__TEMPLATE_ . planned_lines pl
JOIN _SURVEY__TEMPLATE_ . preplot_points pp0 ON ( ( ( pl . line = pp0 . line ) AND ( pl . fsp = pp0 . point ) AND ( pl . class = pp0 . class ) ) ) )
JOIN _SURVEY__TEMPLATE_ . preplot_points pp1 ON ( ( ( pl . line = pp1 . line ) AND ( pl . lsp = pp1 . point ) AND ( pl . class = pp1 . class ) ) ) )
JOIN _SURVEY__TEMPLATE_ . preplot_points pp ON ( ( ( pl . line = pp . line ) AND ( ( ( pp . point > = pl . fsp ) AND ( pp . point < = pl . fsp ) ) OR ( ( pp . point > = pl . fsp ) AND ( pp . point < = pl . fsp ) ) ) AND ( pl . class = pp . class ) ) ) ) ;
ALTER TABLE _SURVEY__TEMPLATE_ . planned_lines_summary OWNER TO postgres ;
2020-08-08 23:59:13 +02:00
--
-- 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 ;
2020-08-10 22:43:07 +02:00
--
-- 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. ' ;
2020-08-26 20:14:07 +02:00
--
-- 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
2022-04-27 10:49:46 +02:00
WHERE ( split_part ( current_setting ( ' search_path ' : : text ) , ' , ' : : text , 1 ) = p . schema )
2020-08-26 20:14:07 +02:00
)
SELECT project . pid ,
project . name ,
2020-09-14 23:54:48 +02:00
project . schema ,
2020-08-26 20:14:07 +02:00
( 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 ;
2020-08-08 23:59:13 +02:00
--
-- 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 ;
2020-09-14 23:54:48 +02:00
--
-- 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 ,
2021-05-25 02:13:50 +02:00
rl . ntbp ,
rl . meta
2020-09-14 23:54:48 +02:00
FROM ( summary s
JOIN _SURVEY__TEMPLATE_ . raw_lines rl USING ( sequence ) ) ;
ALTER TABLE _SURVEY__TEMPLATE_ . raw_lines_summary OWNER TO postgres ;
2020-08-11 15:35:39 +02:00
--
-- 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 ,
2020-10-02 17:56:29 +02:00
rls . ntbp ,
2020-08-11 15:35:39 +02:00
g . geometry
FROM ( _SURVEY__TEMPLATE_ . raw_lines_summary rls
JOIN g USING ( sequence ) ) ;
ALTER TABLE _SURVEY__TEMPLATE_ . raw_lines_summary_geometry OWNER TO postgres ;
2020-08-08 23:59:13 +02:00
--
-- 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 (
2020-08-10 22:43:07 +02:00
SELECT rs . sequence ,
rs . line ,
rs . point ,
2020-08-08 23:59:13 +02:00
rs . objref ,
rs . tstamp ,
rs . hash ,
rs . geometry ,
_SURVEY__TEMPLATE_ . to_binning_grid ( rs . geometry , _SURVEY__TEMPLATE_ . binning_parameters ( ) ) AS ij
2020-08-10 22:43:07 +02:00
FROM _SURVEY__TEMPLATE_ . raw_shots rs
2020-08-08 23:59:13 +02:00
) , 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 ,
2020-08-10 22:43:07 +02:00
sd . line ,
2020-08-08 23:59:13 +02:00
sd . point ,
2020-08-10 22:43:07 +02:00
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
2020-08-08 23:59:13 +02:00
FROM shot_data sd ,
bin ;
ALTER TABLE _SURVEY__TEMPLATE_ . raw_shots_ij_error OWNER TO postgres ;
2020-09-10 20:50:08 +02:00
--
-- Name: raw_shots_preplots; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_ . raw_shots_preplots AS
SELECT rs . sequence ,
rs . line ,
rs . point ,
rs . objref ,
rs . tstamp ,
rs . hash ,
rs . geometry ,
rs . meta ,
rl . line AS sailline ,
rl . remarks ,
rl . ntbp ,
rl . incr ,
rl . meta AS line_meta ,
pp . line AS pp_line ,
pp . point AS pp_point ,
pp . class ,
pp . ntba ,
pp . geometry AS pp_geometry ,
pp . meta AS pp_meta
FROM ( ( _SURVEY__TEMPLATE_ . raw_shots rs
JOIN _SURVEY__TEMPLATE_ . raw_lines rl USING ( sequence ) )
JOIN _SURVEY__TEMPLATE_ . preplot_points pp ON ( ( ( pp . class = ' S ' : : bpchar ) AND ( rs . line = pp . line ) AND ( rs . point = pp . point ) ) ) ) ;
ALTER TABLE _SURVEY__TEMPLATE_ . raw_shots_preplots OWNER TO postgres ;
2020-08-26 20:14:07 +02:00
--
-- 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 ;
2022-03-15 14:17:28 +01:00
--
-- Name: sequences_detail; Type: VIEW; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE VIEW _SURVEY__TEMPLATE_ . sequences_detail AS
SELECT rl . sequence ,
rl . line AS sailline ,
rs . line ,
rs . point ,
rs . tstamp ,
rs . objref AS objrefraw ,
fs . objref AS objreffinal ,
public . st_transform ( pp . geometry , 4326 ) AS geometrypreplot ,
public . st_transform ( rs . geometry , 4326 ) AS geometryraw ,
public . st_transform ( fs . geometry , 4326 ) AS geometryfinal ,
_SURVEY__TEMPLATE_ . ij_error ( ( rs . line ) : : double precision , ( rs . point ) : : double precision , rs . geometry ) AS errorraw ,
_SURVEY__TEMPLATE_ . ij_error ( ( rs . line ) : : double precision , ( rs . point ) : : double precision , fs . geometry ) AS errorfinal ,
json_build_object ( ' preplot ' , pp . meta , ' raw ' , rs . meta , ' final ' , fs . meta ) AS meta
FROM ( ( ( _SURVEY__TEMPLATE_ . raw_lines rl
JOIN _SURVEY__TEMPLATE_ . raw_shots rs USING ( sequence ) )
JOIN _SURVEY__TEMPLATE_ . preplot_points pp ON ( ( ( rs . line = pp . line ) AND ( rs . point = pp . point ) ) ) )
LEFT JOIN _SURVEY__TEMPLATE_ . final_shots fs ON ( ( ( rl . sequence = fs . sequence ) AND ( rs . point = fs . point ) ) ) ) ;
ALTER TABLE _SURVEY__TEMPLATE_ . sequences_detail OWNER TO postgres ;
2020-08-25 17:59:56 +02:00
--
-- 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 ,
2021-05-25 02:13:50 +02:00
rls . meta ,
fls . meta AS meta_final ,
2020-08-25 17:59:56 +02:00
CASE
2020-09-01 12:17:21 +02:00
WHEN ( rls . ntbp IS TRUE ) THEN ' ntbp ' : : text
2020-08-25 17:59:56 +02:00
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 ;
2020-08-12 11:24:52 +02:00
--
2022-03-15 14:17:28 +01:00
-- Name: event_log_full event_log_full_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
2020-08-12 11:24:52 +02:00
--
2022-03-15 14:17:28 +01:00
ALTER TABLE ONLY _SURVEY__TEMPLATE_ . event_log_full
ADD CONSTRAINT event_log_full_pkey PRIMARY KEY ( uid ) ;
2020-08-12 11:24:52 +02:00
2020-08-08 23:59:13 +02:00
--
-- 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
2020-08-10 22:43:07 +02:00
ADD CONSTRAINT final_shots_pkey PRIMARY KEY ( sequence , point ) ;
2020-08-08 23:59:13 +02:00
--
-- Name: info info_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
ALTER TABLE ONLY _SURVEY__TEMPLATE_ . info
ADD CONSTRAINT info_pkey PRIMARY KEY ( key ) ;
2020-08-12 11:24:52 +02:00
--
-- Name: labels labels_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
ALTER TABLE ONLY _SURVEY__TEMPLATE_ . labels
ADD CONSTRAINT labels_pkey PRIMARY KEY ( name ) ;
2020-10-09 13:54:45 +02:00
--
-- Name: planned_lines planned_lines_name_key; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
ALTER TABLE ONLY _SURVEY__TEMPLATE_ . planned_lines
ADD CONSTRAINT planned_lines_name_key UNIQUE ( name ) ;
--
-- Name: planned_lines planned_lines_pkey; Type: CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
ALTER TABLE ONLY _SURVEY__TEMPLATE_ . planned_lines
2021-05-27 20:08:25 +02:00
ADD CONSTRAINT planned_lines_pkey PRIMARY KEY ( sequence ) DEFERRABLE ;
2020-10-09 13:54:45 +02:00
2020-08-08 23:59:13 +02:00
--
-- 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
2020-08-10 22:43:07 +02:00
ADD CONSTRAINT raw_shots_pkey PRIMARY KEY ( sequence , point ) ;
2020-08-08 23:59:13 +02:00
2020-08-12 11:24:52 +02:00
--
2022-03-15 14:17:28 +01:00
-- Name: event_log_id; Type: INDEX; Schema: _SURVEY__TEMPLATE_; Owner: postgres
2020-08-12 11:24:52 +02:00
--
2022-03-15 14:17:28 +01:00
CREATE INDEX event_log_id ON _SURVEY__TEMPLATE_ . event_log_full USING btree ( id ) ;
2020-08-12 11:24:52 +02:00
--
2022-03-15 14:17:28 +01:00
-- Name: event_log_full event_log_full_insert_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres
2020-08-12 11:24:52 +02:00
--
2022-03-15 14:17:28 +01:00
CREATE TRIGGER event_log_full_insert_tg BEFORE INSERT ON _SURVEY__TEMPLATE_ . event_log_full FOR EACH ROW EXECUTE FUNCTION _SURVEY__TEMPLATE_ . event_log_full_insert ( ) ;
2020-08-12 11:24:52 +02:00
2021-05-24 15:55:23 +02:00
--
2022-03-15 14:17:28 +01:00
-- Name: event_log_full event_log_full_notify_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres
2021-05-24 15:55:23 +02:00
--
2022-03-15 14:17:28 +01:00
CREATE TRIGGER event_log_full_notify_tg AFTER INSERT OR DELETE OR UPDATE ON _SURVEY__TEMPLATE_ . event_log_full FOR EACH ROW EXECUTE FUNCTION public . notify ( ' event ' ) ;
2021-05-24 15:55:23 +02:00
--
2022-03-15 14:17:28 +01:00
-- Name: event_log event_log_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres
2021-05-24 15:55:23 +02:00
--
2022-03-15 14:17:28 +01:00
CREATE TRIGGER event_log_tg INSTEAD OF INSERT OR DELETE OR UPDATE ON _SURVEY__TEMPLATE_ . event_log FOR EACH ROW EXECUTE FUNCTION _SURVEY__TEMPLATE_ . event_log_update ( ) ;
2020-09-30 22:45:50 +02:00
2020-10-06 19:19:35 +02:00
--
-- Name: final_lines final_lines_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TRIGGER final_lines_tg AFTER INSERT OR DELETE OR UPDATE ON _SURVEY__TEMPLATE_ . final_lines FOR EACH ROW EXECUTE FUNCTION public . notify ( ' final_lines ' ) ;
2020-10-02 17:30:42 +02:00
--
-- Name: final_shots final_shots_qc_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TRIGGER final_shots_qc_tg AFTER INSERT OR DELETE OR UPDATE ON _SURVEY__TEMPLATE_ . final_shots FOR EACH ROW EXECUTE FUNCTION _SURVEY__TEMPLATE_ . clear_shot_qc ( ) ;
2020-10-06 19:19:35 +02:00
--
-- Name: final_shots final_shots_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TRIGGER final_shots_tg AFTER INSERT OR DELETE OR UPDATE ON _SURVEY__TEMPLATE_ . final_shots FOR EACH STATEMENT EXECUTE FUNCTION public . notify ( ' final_shots ' ) ;
2021-06-19 12:17:26 +02:00
--
-- Name: info info_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TRIGGER info_tg AFTER INSERT OR DELETE OR UPDATE ON _SURVEY__TEMPLATE_ . info FOR EACH ROW EXECUTE FUNCTION public . notify ( ' info ' ) ;
2020-10-09 13:54:45 +02:00
--
-- Name: planned_lines planned_lines_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
2021-05-27 20:09:13 +02:00
CREATE TRIGGER planned_lines_tg AFTER INSERT OR DELETE OR UPDATE ON _SURVEY__TEMPLATE_ . planned_lines FOR EACH ROW EXECUTE FUNCTION public . notify ( ' planned_lines ' ) ;
2020-10-09 13:54:45 +02:00
2020-10-06 19:19:35 +02:00
--
-- Name: preplot_lines preplot_lines_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TRIGGER preplot_lines_tg AFTER INSERT OR DELETE OR UPDATE ON _SURVEY__TEMPLATE_ . preplot_lines FOR EACH ROW EXECUTE FUNCTION public . notify ( ' preplot_lines ' ) ;
--
-- Name: preplot_points preplot_points_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TRIGGER preplot_points_tg AFTER INSERT OR DELETE OR UPDATE ON _SURVEY__TEMPLATE_ . preplot_points FOR EACH STATEMENT EXECUTE FUNCTION public . notify ( ' preplot_points ' ) ;
--
-- Name: raw_lines raw_lines_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TRIGGER raw_lines_tg AFTER INSERT OR DELETE OR UPDATE ON _SURVEY__TEMPLATE_ . raw_lines FOR EACH ROW EXECUTE FUNCTION public . notify ( ' raw_lines ' ) ;
--
-- Name: raw_shots raw_shots_tg; Type: TRIGGER; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
CREATE TRIGGER raw_shots_tg AFTER INSERT OR DELETE OR UPDATE ON _SURVEY__TEMPLATE_ . raw_shots FOR EACH STATEMENT EXECUTE FUNCTION public . notify ( ' raw_shots ' ) ;
2020-08-08 23:59:13 +02:00
--
-- 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 ;
2020-10-09 13:54:45 +02:00
--
-- Name: planned_lines planned_lines_line_class_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
ALTER TABLE ONLY _SURVEY__TEMPLATE_ . planned_lines
ADD CONSTRAINT planned_lines_line_class_fkey FOREIGN KEY ( line , class ) REFERENCES _SURVEY__TEMPLATE_ . preplot_lines ( line , class ) ON UPDATE CASCADE ON DELETE CASCADE ;
--
-- Name: planned_lines planned_lines_line_fsp_class_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
ALTER TABLE ONLY _SURVEY__TEMPLATE_ . planned_lines
ADD CONSTRAINT planned_lines_line_fsp_class_fkey FOREIGN KEY ( line , fsp , class ) REFERENCES _SURVEY__TEMPLATE_ . preplot_points ( line , point , class ) ON UPDATE CASCADE ON DELETE CASCADE ;
--
-- Name: planned_lines planned_lines_line_lsp_class_fkey; Type: FK CONSTRAINT; Schema: _SURVEY__TEMPLATE_; Owner: postgres
--
ALTER TABLE ONLY _SURVEY__TEMPLATE_ . planned_lines
ADD CONSTRAINT planned_lines_line_lsp_class_fkey FOREIGN KEY ( line , lsp , class ) REFERENCES _SURVEY__TEMPLATE_ . preplot_points ( line , point , class ) ON UPDATE CASCADE ON DELETE CASCADE ;
2020-08-08 23:59:13 +02:00
--
-- 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
2020-08-10 22:43:07 +02:00
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 ;
2020-08-08 23:59:13 +02:00
--
-- PostgreSQL database dump complete
--