diff --git a/initdb/02_1_1_signalk_api_tables.sql b/initdb/02_1_1_signalk_api_tables.sql index 963f280..2ed2aae 100644 --- a/initdb/02_1_1_signalk_api_tables.sql +++ b/initdb/02_1_1_signalk_api_tables.sql @@ -99,9 +99,11 @@ CREATE TABLE IF NOT EXISTS api.logbook( vessel_id TEXT NOT NULL REFERENCES api.metadata(vessel_id) ON DELETE RESTRICT, active BOOLEAN DEFAULT false, name TEXT, + _from_moorage_id INT NULL, _from TEXT, _from_lat DOUBLE PRECISION NULL, _from_lng DOUBLE PRECISION NULL, + _to_moorage_id INT NULL, _to TEXT, _to_lat DOUBLE PRECISION NULL, _to_lng DOUBLE PRECISION NULL, @@ -128,6 +130,8 @@ COMMENT ON COLUMN api.logbook.extra IS 'computed signalk metrics of interest, ru -- Index todo! CREATE INDEX logbook_vessel_id_idx ON api.logbook (vessel_id); +CREATE INDEX logbook_from_moorage_id_idx ON api.logbook (_from_moorage_id); +CREATE INDEX logbook_to_moorage_id_idx ON api.logbook (_to_moorage_id); CREATE INDEX ON api.logbook USING GIST ( track_geom ); COMMENT ON COLUMN api.logbook.track_geom IS 'postgis geometry type EPSG:4326 Unit: degres'; CREATE INDEX ON api.logbook USING GIST ( track_geog ); @@ -142,6 +146,7 @@ CREATE TABLE IF NOT EXISTS api.stays( id SERIAL PRIMARY KEY, vessel_id TEXT NOT NULL REFERENCES api.metadata(vessel_id) ON DELETE RESTRICT, active BOOLEAN DEFAULT false, + moorage_id INT NULL, name TEXT, latitude DOUBLE PRECISION NULL, longitude DOUBLE PRECISION NULL, @@ -159,21 +164,20 @@ COMMENT ON TABLE -- Index CREATE INDEX stays_vessel_id_idx ON api.stays (vessel_id); +CREATE INDEX stays_moorage_id_idx ON api.stays (moorage_id); CREATE INDEX ON api.stays USING GIST ( geog ); COMMENT ON COLUMN api.stays.geog IS 'postgis geography type default SRID 4326 Unit: degres'; -- With other SRID ERROR: Only lon/lat coordinate systems are supported in geography. +COMMENT ON COLUMN api.stays.duration IS 'Best to use standard ISO 8601'; --------------------------------------------------------------------------- -- Moorages -- virtual logbook by boat? CREATE TABLE IF NOT EXISTS api.moorages( id SERIAL PRIMARY KEY, - --client_id VARCHAR(255) NOT NULL REFERENCES api.metadata(client_id) ON DELETE RESTRICT, - --client_id VARCHAR(255) NULL, vessel_id TEXT NOT NULL REFERENCES api.metadata(vessel_id) ON DELETE RESTRICT, name TEXT, country TEXT, - stay_id INT NOT NULL, -- needed? stay_code INT DEFAULT 1, -- needed? REFERENCES api.stays_at(stay_code) stay_duration INTERVAL NULL, reference_count INT DEFAULT 1, @@ -181,7 +185,9 @@ CREATE TABLE IF NOT EXISTS api.moorages( longitude DOUBLE PRECISION NULL, geog GEOGRAPHY(POINT) NULL, home_flag BOOLEAN DEFAULT false, - notes TEXT NULL + notes TEXT NULL, + overpass JSONB NULL, + nominatim JSONB NULL ); -- Description COMMENT ON TABLE @@ -193,11 +199,12 @@ CREATE INDEX moorages_vessel_id_idx ON api.moorages (vessel_id); CREATE INDEX ON api.moorages USING GIST ( geog ); COMMENT ON COLUMN api.moorages.geog IS 'postgis geography type default SRID 4326 Unit: degres'; -- With other SRID ERROR: Only lon/lat coordinate systems are supported in geography. +COMMENT ON COLUMN api.moorages.stay_duration IS 'Best to use standard ISO 8601'; --------------------------------------------------------------------------- -- Stay Type CREATE TABLE IF NOT EXISTS api.stays_at( - stay_code INTEGER NOT NULL, + stay_code INTEGER UNIQUE NOT NULL, description TEXT NOT NULL ); -- Description @@ -383,8 +390,12 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$ RAISE WARNING 'Metrics Ignoring metric, vessel_id [%], latitude and longitude are equal [%] [%]', NEW.vessel_id, NEW.latitude, NEW.longitude; RETURN NULL; END IF; - -- Check if status is null - IF NEW.status IS NULL THEN + -- Check if status is null but speed is over 3knots set status to sailing + IF NEW.status IS NULL AND NEW.speedoverground >= 3 THEN + RAISE WARNING 'Metrics Unknown NEW.status, vessel_id [%], null status, set to sailing because of speedoverground is +3 from [%]', NEW.vessel_id, NEW.status; + NEW.status := 'sailing'; + -- Check if status is null then set status to default moored + ELSIF NEW.status IS NULL THEN RAISE WARNING 'Metrics Unknown NEW.status, vessel_id [%], null status, set to default moored from [%]', NEW.vessel_id, NEW.status; NEW.status := 'moored'; END IF; @@ -404,7 +415,7 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$ -- Add stay entry to process queue for further processing INSERT INTO process_queue (channel, payload, stored, ref_id) VALUES ('new_stay', stay_id, now(), current_setting('vessel.id', true)); - RAISE WARNING 'Metrics Insert first stay as no previous metrics exist, stay_id %', stay_id; + RAISE WARNING 'Metrics Insert first stay as no previous metrics exist, stay_id stay_id [%] [%] [%]', stay_id, NEW.status, NEW.time; END IF; -- Check if status is valid enum SELECT NEW.status::name = any(enum_range(null::status)::name[]) INTO valid_status; @@ -433,7 +444,7 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$ (vessel_id, active, _from_time, _from_lat, _from_lng) VALUES (current_setting('vessel.id', true), true, NEW.time, NEW.latitude, NEW.longitude) RETURNING id INTO logbook_id; - RAISE WARNING 'Metrics Insert new logbook, logbook_id %', logbook_id; + RAISE WARNING 'Metrics Insert new logbook, logbook_id [%] [%] [%]', logbook_id, NEW.status, NEW.time; ELSE UPDATE api.logbook SET @@ -454,9 +465,6 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$ departed = NEW.time WHERE id = stay_id; RAISE WARNING 'Metrics Updating Stay end current stay_id [%] [%] [%]', stay_id, NEW.status, NEW.time; - -- Add moorage entry to process queue for further processing - INSERT INTO process_queue (channel, payload, stored, ref_id) - VALUES ('new_moorage', stay_id, now(), current_setting('vessel.id', true)); ELSE RAISE WARNING 'Metrics Invalid stay_id [%] [%]', stay_id, NEW.time; END IF; @@ -483,6 +491,7 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$ -- Add stay entry to process queue for further processing INSERT INTO process_queue (channel, payload, stored, ref_id) VALUES ('new_stay', stay_id, now(), current_setting('vessel.id', true)); + RAISE WARNING 'Metrics Insert new stay, stay_id stay_id [%] [%] [%]', stay_id, NEW.status, NEW.time; ELSE RAISE WARNING 'Metrics Invalid stay_id [%] [%]', stay_id, NEW.time; UPDATE api.stays @@ -507,9 +516,9 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$ WHERE id = logbook_id; -- Add logbook entry to process queue for later processing INSERT INTO process_queue (channel, payload, stored, ref_id) - VALUEs ('new_logbook', logbook_id, now(), current_setting('vessel.id', true)); + VALUES ('new_logbook', logbook_id, now(), current_setting('vessel.id', true)); ELSE - RAISE WARNING 'Metrics Invalid logbook_id [%] [%]', logbook_id, NEW.time; + RAISE WARNING 'Metrics Invalid logbook_id [%] [%] [%]', logbook_id, NEW.status, NEW.time; END IF; END IF; RETURN NEW; -- Finally insert the actual new metric @@ -528,3 +537,57 @@ CREATE TRIGGER metrics_trigger BEFORE INSERT ON api.metrics COMMENT ON TRIGGER metrics_trigger ON api.metrics IS 'BEFORE INSERT ON api.metrics run function metrics_trigger_fn'; + +-- Function update of name and stay_code on logbook and stays reference +DROP FUNCTION IF EXISTS moorage_update_trigger_fn; +CREATE FUNCTION moorage_update_trigger_fn() RETURNS trigger AS $moorage_update$ + DECLARE + BEGIN + RAISE NOTICE 'moorages_update_trigger_fn [%]', NEW; + IF ( OLD.name != NEW.name) THEN + UPDATE api.logbook SET _from = NEW.name WHERE _from_moorage_id = NEW.id; + UPDATE api.logbook SET _to = NEW.name WHERE _to_moorage_id = NEW.id; + END IF; + IF ( OLD.stay_code != NEW.stay_code) THEN + UPDATE api.stays SET stay_code = NEW.stay_code WHERE moorage_id = NEW.id; + END IF; + RETURN NULL; -- result is ignored since this is an AFTER trigger + END; +$moorage_update$ LANGUAGE plpgsql; +-- Description +COMMENT ON FUNCTION + public.moorage_update_trigger_fn + IS 'Automatic update of name and stay_code on logbook and stays reference'; + +-- Triggers moorage update after update +CREATE TRIGGER moorage_update_trigger AFTER UPDATE ON api.moorages + FOR EACH ROW EXECUTE FUNCTION moorage_update_trigger_fn(); +-- Description +COMMENT ON TRIGGER moorage_update_trigger + ON api.moorages + IS 'Automatic update of name and stay_code on logbook and stays reference'; + +-- Function delete logbook and stays reference when delete a moorage +DROP FUNCTION IF EXISTS moorage_delete_trigger_fn; +CREATE FUNCTION moorage_delete_trigger_fn() RETURNS trigger AS $moorage_delete$ + DECLARE + BEGIN + RAISE NOTICE 'moorages_delete_trigger_fn [%]', NEW; + DELETE FROM api.stays WHERE moorage_id = NEW.id; + DELETE FROM api.logbook WHERE _from_moorage_id = NEW.id; + DELETE FROM api.logbook WHERE _to_moorage_id = NEW.id; + RETURN NULL; -- result is ignored since this is an AFTER trigger + END; +$moorage_delete$ LANGUAGE plpgsql; +-- Description +COMMENT ON FUNCTION + public.moorage_delete_trigger_fn + IS 'Automatic delete logbook and stays reference when delete a moorage'; + +-- Triggers moorage delete +CREATE TRIGGER moorage_delete_trigger BEFORE DELETE ON api.moorages + FOR EACH ROW EXECUTE FUNCTION moorage_delete_trigger_fn(); +-- Description +COMMENT ON TRIGGER moorage_delete_trigger + ON api.moorages + IS 'Automatic update of name and stay_code on logbook and stays reference'; diff --git a/initdb/02_1_3_signalk_api_views.sql b/initdb/02_1_3_signalk_api_views.sql index 043a49a..4835472 100644 --- a/initdb/02_1_3_signalk_api_views.sql +++ b/initdb/02_1_3_signalk_api_views.sql @@ -48,7 +48,8 @@ CREATE OR REPLACE VIEW api.logs_view WITH (security_invoker=true,security_barrie _to as "to", _to_time as "ended", distance as "distance", - duration as "duration" + duration as "duration", + _from_moorage_id,_to_moorage_id FROM api.logbook l WHERE _to_time IS NOT NULL ORDER BY _from_time DESC; @@ -66,7 +67,8 @@ CREATE MATERIALIZED VIEW api.logs_mat_view AS _to as "to", _to_time as "ended", distance as "distance", - duration as "duration" + duration as "duration", + _from_moorage_id,_to_moorage_id FROM api.logbook l WHERE _to_time IS NOT NULL ORDER BY _from_time DESC; @@ -90,7 +92,9 @@ CREATE OR REPLACE VIEW api.log_view WITH (security_invoker=true,security_barrier avg_speed as avg_speed, max_speed as max_speed, max_wind_speed as max_wind_speed, - extra as extra + extra as extra, + _from_moorage_id as from_moorage_id, + _to_moorage_id as to_moorage_id FROM api.logbook l WHERE _to_time IS NOT NULL ORDER BY _from_time DESC; @@ -104,30 +108,28 @@ COMMENT ON VIEW DROP VIEW IF EXISTS api.stays_view; CREATE OR REPLACE VIEW api.stays_view WITH (security_invoker=true,security_barrier=true) AS SELECT s.id, - concat( - extract(DAYS FROM (s.departed-s.arrived)::interval), - ' days', - --DATE_TRUNC('day', s.departed-s.arrived), - ' stay at ', - s.name, - ' in ', - RTRIM(TO_CHAR(s.departed, 'Month')), - ' ', - TO_CHAR(s.departed, 'YYYY') - ) as "name", - s.name AS "moorage", + s.name AS "name", + m.name AS "moorage", m.id AS "moorage_id", (s.departed-s.arrived) AS "duration", sa.description AS "stayed_at", sa.stay_code AS "stayed_at_id", s.arrived AS "arrived", + _from.id as "arrived_log_id", + _from._to_moorage_id as "arrived_from_moorage_id", + _from._to as "arrived_from_moorage_name", s.departed AS "departed", + _to.id AS "departed_log_id", + _to._from_moorage_id AS "departed_to_moorage_id", + _to._from AS "departed_to_moorage_name", s.notes AS "notes" FROM api.stays s, api.stays_at sa, api.moorages m - WHERE departed IS NOT NULL + LEFT JOIN api.logbook As _from ON _from._from_moorage_id = m.id + LEFT JOIN api.logbook AS _to ON _to._to_moorage_id = m.id + WHERE s.departed IS NOT NULL AND s.name IS NOT NULL AND s.stay_code = sa.stay_code - AND s.id = m.stay_id + AND s.moorage_id = m.id ORDER BY s.arrived DESC; -- Description COMMENT ON VIEW @@ -137,30 +139,28 @@ COMMENT ON VIEW DROP VIEW IF EXISTS api.stay_view; CREATE OR REPLACE VIEW api.stay_view WITH (security_invoker=true,security_barrier=true) AS SELECT s.id, - concat( - extract(DAYS FROM (s.departed-s.arrived)::interval), - ' days', - --DATE_TRUNC('day', s.departed-s.arrived), - ' stay at ', - s.name, - ' in ', - RTRIM(TO_CHAR(s.departed, 'Month')), - ' ', - TO_CHAR(s.departed, 'YYYY') - ) as "name", - s.name AS "moorage", + s.name AS "name", + m.name AS "moorage", m.id AS "moorage_id", (s.departed-s.arrived) AS "duration", sa.description AS "stayed_at", sa.stay_code AS "stayed_at_id", s.arrived AS "arrived", + _from.id as "arrived_log_id", + _from._to_moorage_id as "arrived_from_moorage_id", + _from._to as "arrived_from_moorage_name", s.departed AS "departed", + _to.id AS "departed_log_id", + _to._from_moorage_id AS "departed_to_moorage_id", + _to._from AS "departed_to_moorage_name", s.notes AS "notes" FROM api.stays s, api.stays_at sa, api.moorages m - WHERE departed IS NOT NULL + LEFT JOIN api.logbook As _from ON _from._from_moorage_id = m.id + LEFT JOIN api.logbook AS _to ON _to._to_moorage_id = m.id + WHERE s.departed IS NOT NULL AND s.name IS NOT NULL AND s.stay_code = sa.stay_code - AND s.id = m.stay_id + AND s.moorage_id = m.id ORDER BY s.arrived DESC; -- Description COMMENT ON VIEW @@ -191,17 +191,20 @@ CREATE OR REPLACE VIEW api.moorages_view WITH (security_invoker=true,security_ba sa.description AS Default_Stay, sa.stay_code AS Default_Stay_Id, EXTRACT(DAY FROM justify_hours ( m.stay_duration )) AS Total_Stay, -- in days + m.stay_duration AS Total_Duration, m.reference_count AS Arrivals_Departures -- m.geog -- m.stay_duration, -- justify_hours ( m.stay_duration ) FROM api.moorages m, api.stays_at sa - WHERE m.name IS NOT NULL - AND geog IS NOT NULL +-- m.stay_duration is only process on a stay + WHERE m.stay_duration IS NOT NULL + AND m.geog IS NOT NULL AND m.stay_code = sa.stay_code GROUP BY m.id,m.name,sa.description,m.stay_duration,m.reference_count,m.geog,sa.stay_code -- ORDER BY 4 DESC; - ORDER BY m.reference_count DESC; +-- ORDER BY m.reference_count DESC; + ORDER BY m.stay_duration DESC; -- Description COMMENT ON VIEW api.moorages_view @@ -215,11 +218,13 @@ CREATE OR REPLACE VIEW api.moorage_view WITH (security_invoker=true,security_bar sa.stay_code AS Default_Stay_Id, m.home_flag AS Home, EXTRACT(DAY FROM justify_hours ( m.stay_duration )) AS Total_Stay, + m.stay_duration AS Total_Duration, m.reference_count AS Arrivals_Departures, m.notes -- m.geog FROM api.moorages m, api.stays_at sa - WHERE m.name IS NOT NULL +-- m.stay_duration is only process on a stay + WHERE m.stay_duration IS NOT NULL AND geog IS NOT NULL AND m.stay_code = sa.stay_code; -- Description @@ -227,6 +232,21 @@ COMMENT ON VIEW api.moorage_view IS 'Moorage details web view'; +DROP VIEW IF EXISTS api.moorages_stays_view; +CREATE OR REPLACE VIEW api.moorages_stays_view WITH (security_invoker=true,security_barrier=true) AS -- TODO + SELECT + _to.id AS _to_id,_to._to_time, + _from.id AS _from_id,_from._from_time, + m.stay_code,m.stay_duration,m.id + FROM api.moorages m + LEFT JOIN api.logbook As _from ON _from._from_moorage_id = m.id + LEFT JOIN api.logbook AS _to ON _to._to_moorage_id = m.id + ORDER BY _to._to_time DESC; +-- Description +COMMENT ON VIEW + api.moorages_stays_view + IS 'Moorages stay listing web view'; + -- All moorage in 100 meters from the start of a logbook. -- ST_DistanceSphere Returns minimum distance in meters between two lon/lat points. --SELECT @@ -269,7 +289,7 @@ CREATE OR REPLACE VIEW api.stats_logs_view WITH (security_invoker=true,security_ concat( max(l.distance), ' NM, ', max(l.duration), ' hours') AS "longest_nonstop_sail" FROM api.logbook l) SELECT - m.name as Name, + m.name AS name, fm.time AS first, lm.time AS last, l.* diff --git a/initdb/02_3_2_signalk_public_functions.sql b/initdb/02_3_2_signalk_public_functions.sql index 9d6d957..4be49fa 100644 --- a/initdb/02_3_2_signalk_public_functions.sql +++ b/initdb/02_3_2_signalk_public_functions.sql @@ -129,6 +129,9 @@ CREATE FUNCTION public.logbook_update_geojson_fn(IN _id integer, IN _start text, max_speed, max_wind_speed, _from_time, + _to_time + _from_moorage_id, + _to_moorage_id, notes, track_geom FROM api.logbook @@ -367,9 +370,11 @@ DROP FUNCTION IF EXISTS process_logbook_queue_fn; CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void AS $process_logbook_queue$ DECLARE logbook_rec record; - from_name varchar; - to_name varchar; - log_name varchar; + from_name text; + to_name text; + log_name text; + from_moorage record; + to_moorage record; avg_rec record; geo_rec record; log_settings jsonb; @@ -472,14 +477,19 @@ CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void RETURN; END IF; + -- Do we have an existing moorage within 300m of the new log + -- generate logbook name, concat _from_location and _to_location from moorage name + from_moorage := process_lat_lon_fn(logbook_rec._from_lng::NUMERIC, logbook_rec._from_lat::NUMERIC); + to_moorage := process_lat_lon_fn(logbook_rec._to_lng::NUMERIC, logbook_rec._to_lat::NUMERIC); + SELECT CONCAT(from_moorage.moorage_name, ' to ' , to_moorage.moorage_name) INTO log_name; -- Generate logbook name, concat _from_location and _to_location -- geo reverse _from_lng _from_lat -- geo reverse _to_lng _to_lat - geo := reverse_geocode_py_fn('nominatim', logbook_rec._from_lng::NUMERIC, logbook_rec._from_lat::NUMERIC); - from_name := geo->>'name'; - geo := reverse_geocode_py_fn('nominatim', logbook_rec._to_lng::NUMERIC, logbook_rec._to_lat::NUMERIC); - to_name := geo->>'name'; - SELECT CONCAT(from_name, ' to ' , to_name) INTO log_name; + --geo := reverse_geocode_py_fn('nominatim', logbook_rec._from_lng::NUMERIC, logbook_rec._from_lat::NUMERIC); + --from_name := geo->>'name'; + --geo := reverse_geocode_py_fn('nominatim', logbook_rec._to_lng::NUMERIC, logbook_rec._to_lat::NUMERIC); + --to_name := geo->>'name'; + --SELECT CONCAT(from_name, ' to ' , to_name) INTO log_name; -- Process `propulsion.*.runTime` and `navigation.log` -- Calculate extra json @@ -492,8 +502,10 @@ CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void avg_speed = avg_rec.avg_speed, max_speed = avg_rec.max_speed, max_wind_speed = avg_rec.max_wind_speed, - _from = from_name, - _to = to_name, + _from = from_moorage.moorage_name, + _from_moorage_id = from_moorage.moorage_id, + _to_moorage_id = to_moorage.moorage_id, + _to = to_moorage.moorage_name, name = log_name, track_geom = geo_rec._track_geom, distance = geo_rec._track_distance, @@ -532,7 +544,7 @@ DROP FUNCTION IF EXISTS process_stay_queue_fn; CREATE OR REPLACE FUNCTION process_stay_queue_fn(IN _id integer) RETURNS void AS $process_stay_queue$ DECLARE stay_rec record; - geo jsonb; + moorage record; BEGIN RAISE NOTICE 'process_stay_queue_fn'; -- If _id is valid, not NULL @@ -553,17 +565,40 @@ CREATE OR REPLACE FUNCTION process_stay_queue_fn(IN _id integer) RETURNS void AS END IF; PERFORM set_config('vessel.id', stay_rec.vessel_id, false); - -- geo reverse _lng _lat - geo := reverse_geocode_py_fn('nominatim', stay_rec.longitude::NUMERIC, stay_rec.latitude::NUMERIC); - RAISE NOTICE 'Updating stay entry [%]', stay_rec.id; + -- Do we have an existing moorage within 300m of the new stay + moorage := process_lat_lon_fn(stay_rec.longitude::NUMERIC, stay_rec.latitude::NUMERIC); + + RAISE NOTICE '-> process_stay_queue_fn Updating stay entry [%]', stay_rec.id; UPDATE api.stays SET - name = coalesce(geo->>'name', null), + name = concat( + ROUND( EXTRACT(epoch from (stay_rec.departed::timestamp without time zone - stay_rec.arrived::timestamp without time zone)::INTERVAL / 86400) ), + ' days stay at ', + moorage.moorage_name, + ' in ', + RTRIM(TO_CHAR(stay_rec.departed, 'Month')), + ' ', + TO_CHAR(stay_rec.departed, 'YYYY') + ), + moorage_id = moorage.moorage_id, + duration = (stay_rec.departed::timestamp without time zone - stay_rec.arrived::timestamp without time zone)::INTERVAL, + stay_code = moorage.moorage_type, geog = Geography(ST_MakePoint(stay_rec.longitude, stay_rec.latitude)) WHERE id = stay_rec.id; - -- Notification email/pushover? + RAISE NOTICE '-> process_stay_queue_fn Updating moorage entry [%]', moorage.moorage_id; + UPDATE api.moorages + SET + reference_count = ( + with _from as (select count(*) from api.logbook where _from_moorage_id = moorage.moorage_id), + _to as (select count(*) from api.logbook where _to_moorage_id = moorage.moorage_id) + select _from.count+_to.count from _from,_to + ), + stay_duration = ( + select sum(departed-arrived) from api.stays where moorage_id = moorage.moorage_id + ) + WHERE id = moorage.moorage_id; END; $process_stay_queue$ LANGUAGE plpgsql; -- Description @@ -572,7 +607,7 @@ COMMENT ON FUNCTION IS 'Update stay details, reverse_geocode_py_fn'; -- Handle moorage insert or update from stays --- todo valide geography unit +-- todo validate geography unit -- https://postgis.net/docs/ST_DWithin.html DROP FUNCTION IF EXISTS process_moorage_queue_fn; CREATE OR REPLACE FUNCTION process_moorage_queue_fn(IN _id integer) RETURNS void AS $process_moorage_queue$ @@ -605,44 +640,44 @@ CREATE OR REPLACE FUNCTION process_moorage_queue_fn(IN _id integer) RETURNS void PERFORM set_config('vessel.id', stay_rec.vessel_id, false); - -- Do we have an existing stay within 100m of the new moorage - FOR moorage_rec in - SELECT - * - FROM api.moorages - WHERE - latitude IS NOT NULL - AND longitude IS NOT NULL + -- Do we have an existing stay within 200m of the new moorage + FOR moorage_rec in + SELECT + * + FROM api.moorages + WHERE + latitude IS NOT NULL + AND longitude IS NOT NULL AND geog IS NOT NULL - AND ST_DWithin( - -- Geography(ST_MakePoint(stay_rec._lng, stay_rec._lat)), + AND ST_DWithin( + -- Geography(ST_MakePoint(stay_rec._lng, stay_rec._lat)), stay_rec.geog, - -- Geography(ST_MakePoint(longitude, latitude)), + -- Geography(ST_MakePoint(longitude, latitude)), geog, - 100 -- in meters ? - ) - ORDER BY id ASC - LOOP - -- found previous stay within 100m of the new moorage - IF moorage_rec.id IS NOT NULL AND moorage_rec.id > 0 THEN - RAISE NOTICE 'Found previous stay within 100m of moorage %', moorage_rec; - EXIT; -- exit loop - END IF; - END LOOP; + 200 -- in meters ? + ) + ORDER BY id ASC + LOOP + -- found previous stay within 200m of the new moorage + IF moorage_rec.id IS NOT NULL AND moorage_rec.id > 0 THEN + RAISE NOTICE 'Found previous stay within 200m of moorage %', moorage_rec; + EXIT; -- exit loop + END IF; + END LOOP; - -- if with in 100m update reference count and stay duration - -- else insert new entry - IF moorage_rec.id IS NOT NULL AND moorage_rec.id > 0 THEN - RAISE NOTICE 'Update moorage %', moorage_rec; - UPDATE api.moorages - SET - reference_count = moorage_rec.reference_count + 1, - stay_duration = + -- if with in 200m update reference count and stay duration + -- else insert new entry + IF moorage_rec.id IS NOT NULL AND moorage_rec.id > 0 THEN + RAISE NOTICE 'Update moorage %', moorage_rec; + UPDATE api.moorages + SET + reference_count = moorage_rec.reference_count + 1, + stay_duration = moorage_rec.stay_duration + (stay_rec.departed::timestamp without time zone - stay_rec.arrived::timestamp without time zone) - WHERE id = moorage_rec.id; - ELSE - RAISE NOTICE 'Insert new moorage entry from stay %', stay_rec; + WHERE id = moorage_rec.id; + ELSE + RAISE NOTICE 'Insert new moorage entry from stay %', stay_rec; -- Set the moorage name and country if lat,lon IF stay_rec.longitude IS NOT NULL AND stay_rec.latitude IS NOT NULL THEN geo := reverse_geocode_py_fn('nominatim', stay_rec.longitude::NUMERIC, stay_rec.latitude::NUMERIC); @@ -650,21 +685,21 @@ CREATE OR REPLACE FUNCTION process_moorage_queue_fn(IN _id integer) RETURNS void moorage_rec.country = geo->>'country_code'; END IF; -- Insert new moorage from stay - INSERT INTO api.moorages - (vessel_id, name, country, stay_id, stay_code, stay_duration, reference_count, latitude, longitude, geog) - VALUES ( + INSERT INTO api.moorages + (vessel_id, name, country, stay_id, stay_code, stay_duration, reference_count, latitude, longitude, geog) + VALUES ( stay_rec.vessel_id, coalesce(moorage_rec.name, null), coalesce(moorage_rec.country, null), - stay_rec.id, - stay_rec.stay_code, - (stay_rec.departed::timestamp without time zone - stay_rec.arrived::timestamp without time zone), - 1, -- default reference_count - stay_rec.latitude, - stay_rec.longitude, + stay_rec.id, + stay_rec.stay_code, + (stay_rec.departed::timestamp without time zone - stay_rec.arrived::timestamp without time zone), + 1, -- default reference_count + stay_rec.latitude, + stay_rec.longitude, Geography(ST_MakePoint(stay_rec.longitude, stay_rec.latitude)) ); - END IF; + END IF; -- Process badges PERFORM badges_moorages_fn(); @@ -1403,6 +1438,121 @@ COMMENT ON FUNCTION public.process_logbook_queue_fn IS 'Avoid/ignore/delete logbook stationary movement or time sync issue'; +DROP FUNCTION IF EXISTS process_lat_lon_fn; +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 _id is valid, not NULL + IF lon IS NULL OR lat IS NULL THEN + RAISE WARNING '-> process_lat_lon_fn invalid input lon,lat %', _id; + --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 200m 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:[%] 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; + 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 + -- geo reverse _lng _lat + geo := reverse_geocode_py_fn('nominatim', lon::NUMERIC, lat::NUMERIC); + moorage_name := geo->>'name'; + moorage_country := geo->>'country_code'; + 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; +-- Description +COMMENT ON FUNCTION + public.process_lat_lon_fn + IS 'Add or Update moorage base on lat/lon'; + --------------------------------------------------------------------------- -- TODO add alert monitoring for Battery @@ -1461,6 +1611,7 @@ BEGIN OR _path = '/rpc/update_user_preferences_fn' OR _path = '/rpc/versions_fn' OR _path = '/rpc/email_fn' + OR _path = '/rpc/login' OR _path = '/' THEN RETURN; END IF; @@ -1594,7 +1745,7 @@ BEGIN perform public.cron_process_monitor_online_fn(); perform public.cron_process_new_logbook_fn(); perform public.cron_process_new_stay_fn(); - perform public.cron_process_new_moorage_fn(); + --perform public.cron_process_new_moorage_fn(); perform public.cron_process_monitor_offline_fn(); END $$ language plpgsql; diff --git a/initdb/04pgcron.sql b/initdb/04pgcron.sql index fe61d67..8045035 100644 --- a/initdb/04pgcron.sql +++ b/initdb/04pgcron.sql @@ -19,7 +19,7 @@ SELECT cron.schedule('cron_new_stay', '*/6 * * * *', 'select public.cron_process --UPDATE cron.job SET database = 'signalk' where jobname = 'cron_new_stay'; -- Create a every 6 minute job cron_process_new_moorage_fn, delay from stay to give time to generate geo reverse location, eg: name -SELECT cron.schedule('cron_new_moorage', '*/7 * * * *', 'select public.cron_process_new_moorage_fn()'); +--SELECT cron.schedule('cron_new_moorage', '*/7 * * * *', 'select public.cron_process_new_moorage_fn()'); --UPDATE cron.job SET database = 'signalk' where jobname = 'cron_new_moorage'; -- Create a every 10 minute job cron_process_monitor_offline_fn