From e9dea3b124a2c8112fcda62ddaf1128f7ab90c9a Mon Sep 17 00:00:00 2001 From: xbgmsharp Date: Sat, 2 Mar 2024 11:19:42 +0100 Subject: [PATCH] Add migration 202403, Add new conversion metersToKnots, Update logbook_update_geojson_fn expose data in nautical units, Update process_lat_lon_fn process moorage to always set a country --- initdb/99_migrations_202403.sql | 206 ++++++++++++++++++++++++++++++++ 1 file changed, 206 insertions(+) create mode 100644 initdb/99_migrations_202403.sql diff --git a/initdb/99_migrations_202403.sql b/initdb/99_migrations_202403.sql new file mode 100644 index 0000000..9152ea8 --- /dev/null +++ b/initdb/99_migrations_202403.sql @@ -0,0 +1,206 @@ +--------------------------------------------------------------------------- +-- Copyright 2021-2024 Francois Lacroix +-- This file is part of PostgSail which is released under Apache License, Version 2.0 (the "License"). +-- See file LICENSE or go to http://www.apache.org/licenses/LICENSE-2.0 for full license details. +-- +-- Migration March 2024 +-- +-- List current database +select current_database(); + +-- connect to the DB +\c signalk + +\echo 'Force timezone, just in case' +set timezone to 'UTC'; + +CREATE OR REPLACE FUNCTION process_lat_lon_fn(IN lon NUMERIC, IN lat NUMERIC, + OUT moorage_id INTEGER, + OUT moorage_type INTEGER, + OUT moorage_name TEXT, + OUT moorage_country TEXT +) AS $process_lat_lon$ + DECLARE + stay_rec record; + --moorage_id INTEGER := NULL; + --moorage_type INTEGER := 1; -- Unknown + --moorage_name TEXT := NULL; + --moorage_country TEXT := NULL; + existing_rec record; + geo jsonb; + overpass jsonb; + BEGIN + RAISE NOTICE '-> process_lat_lon_fn'; + IF lon IS NULL OR lat IS NULL THEN + RAISE WARNING '-> process_lat_lon_fn invalid input lon %, lat %', lon, lat; + --return NULL; + END IF; + + -- Do we have an existing moorages within 300m of the new stay + FOR existing_rec in + SELECT + * + FROM api.moorages m + WHERE + m.latitude IS NOT NULL + AND m.longitude IS NOT NULL + AND m.geog IS NOT NULL + AND ST_DWithin( + Geography(ST_MakePoint(m.longitude, m.latitude)), + Geography(ST_MakePoint(lon, lat)), + 300 -- in meters + ) + AND m.vessel_id = current_setting('vessel.id', false) + ORDER BY id ASC + LOOP + -- found previous stay within 300m of the new moorage + IF existing_rec.id IS NOT NULL AND existing_rec.id > 0 THEN + RAISE NOTICE '-> process_lat_lon_fn found previous moorages within 300m %', existing_rec; + EXIT; -- exit loop + END IF; + END LOOP; + + -- if with in 300m use existing name and stay_code + -- else insert new entry + IF existing_rec.id IS NOT NULL AND existing_rec.id > 0 THEN + RAISE NOTICE '-> process_lat_lon_fn found close by moorage using existing name and stay_code %', existing_rec; + moorage_id := existing_rec.id; + moorage_name := existing_rec.name; + moorage_type := existing_rec.stay_code; + ELSE + RAISE NOTICE '-> process_lat_lon_fn create new moorage'; + -- query overpass api to guess moorage type + overpass := overpass_py_fn(lon::NUMERIC, lat::NUMERIC); + RAISE NOTICE '-> process_lat_lon_fn overpass name:[%] seamark:type:[%]', overpass->'name', overpass->'seamark:type'; + moorage_type = 1; -- Unknown + IF overpass->>'seamark:type' = 'harbour' AND overpass->>'seamark:harbour:category' = 'marina' then + moorage_type = 4; -- Dock + ELSIF overpass->>'seamark:type' = 'mooring' AND overpass->>'seamark:mooring:category' = 'buoy' then + moorage_type = 3; -- Mooring Buoy + ELSIF overpass->>'seamark:type' ~ '(anchorage|anchor_berth|berth)' OR overpass->>'natural' ~ '(bay|beach)' then + moorage_type = 2; -- Anchor + ELSIF overpass->>'seamark:type' = 'mooring' then + moorage_type = 3; -- Mooring Buoy + ELSIF overpass->>'leisure' = 'marina' then + moorage_type = 4; -- Dock + END IF; + -- geo reverse _lng _lat + geo := reverse_geocode_py_fn('nominatim', lon::NUMERIC, lat::NUMERIC); + moorage_country := geo->>'country_code'; + IF overpass->>'name:en' IS NOT NULL then + moorage_name = overpass->>'name:en'; + ELSIF overpass->>'name' IS NOT NULL then + moorage_name = overpass->>'name'; + ELSE + moorage_name := geo->>'name'; + END IF; + RAISE NOTICE '-> process_lat_lon_fn output name:[%] type:[%]', moorage_name, moorage_type; + RAISE NOTICE '-> process_lat_lon_fn insert new moorage for [%] name:[%] type:[%]', current_setting('vessel.id', false), moorage_name, moorage_type; + -- Insert new moorage from stay + INSERT INTO api.moorages + (vessel_id, name, country, stay_code, reference_count, latitude, longitude, geog, overpass, nominatim) + VALUES ( + current_setting('vessel.id', false), + coalesce(moorage_name, null), + coalesce(moorage_country, null), + moorage_type, + 1, + lat, + lon, + Geography(ST_MakePoint(lon, lat)), + coalesce(overpass, null), + coalesce(geo, null) + ) returning id into moorage_id; + -- Add moorage entry to process queue for reference + --INSERT INTO process_queue (channel, payload, stored, ref_id, processed) + -- VALUES ('new_moorage', moorage_id, now(), current_setting('vessel.id', true), now()); + END IF; + --return json_build_object( + -- 'id', moorage_id, + -- 'name', moorage_name, + -- 'type', moorage_type + -- )::jsonb; + END; +$process_lat_lon$ LANGUAGE plpgsql; + +CREATE or replace FUNCTION public.logbook_update_geojson_fn(IN _id integer, IN _start text, IN _end text, + OUT _track_geojson JSON + ) AS $logbook_geojson$ + declare + log_geojson jsonb; + metrics_geojson jsonb; + _map jsonb; + begin + -- GeoJson Feature Logbook linestring + SELECT + ST_AsGeoJSON(log.*) into log_geojson + FROM + ( SELECT + id,name, + distance, + duration, + avg_speed, + max_speed, + max_wind_speed, + _from_time, + _to_time + _from_moorage_id, + _to_moorage_id, + notes, + track_geom + FROM api.logbook + WHERE id = _id + ) AS log; + -- GeoJson Feature Metrics point + SELECT + json_agg(ST_AsGeoJSON(t.*)::json) into metrics_geojson + FROM ( + ( SELECT + time, + courseovergroundtrue, + speedoverground, + windspeedapparent, + longitude,latitude, + '' AS notes, + coalesce(metersToKnots((metrics->'environment.wind.speedTrue')::NUMERIC), null) as truewindspeed, + coalesce(radiantToDegrees((metrics->'environment.wind.directionTrue')::NUMERIC), null) as truewinddirection, + coalesce(status, null) as status, + st_makepoint(longitude,latitude) AS geo_point + FROM api.metrics m + WHERE m.latitude IS NOT NULL + AND m.longitude IS NOT NULL + AND time >= _start::TIMESTAMPTZ + AND time <= _end::TIMESTAMPTZ + AND vessel_id = current_setting('vessel.id', false) + ORDER BY m.time ASC + ) + ) AS t; + + -- Merge jsonb + SELECT log_geojson::jsonb || metrics_geojson::jsonb into _map; + -- output + SELECT + json_build_object( + 'type', 'FeatureCollection', + 'features', _map + ) into _track_geojson; + END; +$logbook_geojson$ LANGUAGE plpgsql; + +CREATE OR REPLACE FUNCTION public.metersToKnots(IN meters NUMERIC) +RETURNS NUMERIC +AS $$ +BEGIN + RETURN ROUND(((meters * 1.9438445) * 10) / 10, 2); +END +$$ +LANGUAGE plpgsql IMMUTABLE; +-- Description +COMMENT ON FUNCTION + public.metersToKnots + IS 'convert speed meters/s To Knots'; + +-- Update version +UPDATE public.app_settings + SET value='0.7.1' + WHERE "name"='app.version';