diff --git a/etc/db/database-template.sql b/etc/db/database-template.sql index 149135d..0ed46f5 100644 --- a/etc/db/database-template.sql +++ b/etc/db/database-template.sql @@ -3,7 +3,7 @@ -- -- Dumped from database version 14.2 --- Dumped by pg_dump version 14.1 +-- Dumped by pg_dump version 14.2 SET statement_timeout = 0; SET lock_timeout = 0; @@ -20,7 +20,7 @@ SET row_security = off; -- Name: dougal; Type: DATABASE; Schema: -; Owner: postgres -- -CREATE DATABASE dougal WITH TEMPLATE = template0 ENCODING = 'UTF8' LC_COLLATE = 'C' LC_CTYPE = 'en_GB.UTF-8'; +CREATE DATABASE dougal WITH TEMPLATE = template0 ENCODING = 'UTF8' LOCALE = 'en_GB.UTF-8'; ALTER DATABASE dougal OWNER TO postgres; @@ -82,7 +82,7 @@ CREATE EXTENSION IF NOT EXISTS btree_gist WITH SCHEMA public; -- --- Name: EXTENSION btree_gist; Type: COMMENT; Schema: -; Owner: +-- Name: EXTENSION btree_gist; Type: COMMENT; Schema: -; Owner: -- COMMENT ON EXTENSION btree_gist IS 'support for indexing common datatypes in GiST'; @@ -96,7 +96,7 @@ CREATE EXTENSION IF NOT EXISTS postgis WITH SCHEMA public; -- --- Name: EXTENSION postgis; Type: COMMENT; Schema: -; Owner: +-- Name: EXTENSION postgis; Type: COMMENT; Schema: -; Owner: -- COMMENT ON EXTENSION postgis IS 'PostGIS geometry, geography, and raster spatial types and functions'; @@ -110,7 +110,7 @@ CREATE EXTENSION IF NOT EXISTS postgis_sfcgal WITH SCHEMA public; -- --- Name: EXTENSION postgis_sfcgal; Type: COMMENT; Schema: -; Owner: +-- Name: EXTENSION postgis_sfcgal; Type: COMMENT; Schema: -; Owner: -- COMMENT ON EXTENSION postgis_sfcgal IS 'PostGIS SFCGAL functions'; @@ -124,7 +124,7 @@ CREATE EXTENSION IF NOT EXISTS postgis_topology WITH SCHEMA topology; -- --- Name: EXTENSION postgis_topology; Type: COMMENT; Schema: -; Owner: +-- Name: EXTENSION postgis_topology; Type: COMMENT; Schema: -; Owner: -- COMMENT ON EXTENSION postgis_topology IS 'PostGIS topology spatial types and functions'; @@ -144,6 +144,34 @@ CREATE TYPE public.queue_item_status AS ENUM ( ALTER TYPE public.queue_item_status OWNER TO postgres; +-- +-- Name: geometry_from_tstamp(timestamp with time zone, numeric); Type: FUNCTION; Schema: public; Owner: postgres +-- + +CREATE FUNCTION public.geometry_from_tstamp(ts timestamp with time zone, tolerance numeric, OUT geometry public.geometry, OUT delta numeric) RETURNS record + LANGUAGE sql + AS $$ + SELECT + geometry, + extract('epoch' FROM (meta->>'tstamp')::timestamptz - ts ) AS delta + FROM real_time_inputs + WHERE + geometry IS NOT NULL AND + abs(extract('epoch' FROM (meta->>'tstamp')::timestamptz - ts )) < tolerance + ORDER BY abs(extract('epoch' FROM (meta->>'tstamp')::timestamptz - ts )) + LIMIT 1; + $$; + + +ALTER FUNCTION public.geometry_from_tstamp(ts timestamp with time zone, tolerance numeric, OUT geometry public.geometry, OUT delta numeric) OWNER TO postgres; + +-- +-- Name: FUNCTION geometry_from_tstamp(ts timestamp with time zone, tolerance numeric, OUT geometry public.geometry, OUT delta numeric); Type: COMMENT; Schema: public; Owner: postgres +-- + +COMMENT ON FUNCTION public.geometry_from_tstamp(ts timestamp with time zone, tolerance numeric, OUT geometry public.geometry, OUT delta numeric) IS 'Get geometry from timestamp'; + + -- -- Name: notify(); Type: FUNCTION; Schema: public; Owner: postgres -- @@ -400,6 +428,13 @@ ALTER TABLE ONLY public.queue_items ADD CONSTRAINT queue_items_pkey PRIMARY KEY (item_id); +-- +-- Name: meta_tstamp_idx; Type: INDEX; Schema: public; Owner: postgres +-- + +CREATE INDEX meta_tstamp_idx ON public.real_time_inputs USING btree (((meta ->> 'tstamp'::text)) DESC); + + -- -- Name: tstamp_idx; Type: INDEX; Schema: public; Owner: postgres -- @@ -449,6 +484,7 @@ CREATE TRIGGER real_time_inputs_tg AFTER INSERT ON public.real_time_inputs FOR E ALTER TABLE ONLY public.queue_items ADD CONSTRAINT queue_items_parent_id_fkey FOREIGN KEY (parent_id) REFERENCES public.queue_items(item_id); + -- -- PostgreSQL database dump complete -- diff --git a/etc/db/database-version.sql b/etc/db/database-version.sql index 375a31b..80a1065 100644 --- a/etc/db/database-version.sql +++ b/etc/db/database-version.sql @@ -1,3 +1,3 @@ -INSERT INTO public.info VALUES ('version', '{"db_schema": "0.3.3"}') +INSERT INTO public.info VALUES ('version', '{"db_schema": "0.3.4"}') ON CONFLICT (key) DO UPDATE - SET value = public.info.value || '{"db_schema": "0.3.3"}' WHERE public.info.key = 'version'; + SET value = public.info.value || '{"db_schema": "0.3.4"}' WHERE public.info.key = 'version'; diff --git a/etc/db/schema-template.sql b/etc/db/schema-template.sql index b1dd8b5..c3ebb29 100644 --- a/etc/db/schema-template.sql +++ b/etc/db/schema-template.sql @@ -2,8 +2,8 @@ -- PostgreSQL database dump -- --- Dumped from database version 14.1 --- Dumped by pg_dump version 14.1 +-- Dumped from database version 14.2 +-- Dumped by pg_dump version 14.2 SET statement_timeout = 0; SET lock_timeout = 0; @@ -274,6 +274,72 @@ $$; ALTER FUNCTION _SURVEY__TEMPLATE_.assoc_tstamp() OWNER TO postgres; +-- +-- 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'; + + -- -- Name: binning_parameters(); Type: FUNCTION; Schema: _SURVEY__TEMPLATE_; Owner: postgres --