13 Commits

Author SHA1 Message Date
xbgmsharp
4c80d041cc Update tests versions, PostgreSQL 16.10, timescaledb 2.21.3 2025-08-18 19:36:57 +02:00
xbgmsharp
12e4baf662 Release PostgSail 0.9.3 2025-08-03 10:37:02 +02:00
xbgmsharp
faf62ed9a3 Update tests, PostgSail 0.9.3 2025-08-02 16:15:12 +02:00
xbgmsharp
40bdb9620f Update tests, PostgSail 0.9.3 2025-08-02 16:13:29 +02:00
xbgmsharp
8fe84ea80c Update migration 202507
- Update plugin upgrade message
- Update api.login, update the connected_at field to the current time
- Update monitoring_history_fn to use custom user settings for metrics
- Update cron_alerts_fn to check for alerts, filters out empty strings (""), so they are not included in the result.
- Update process_pre_logbook_fn to detect and avoid logbook we more than 1000NM in less 15h
2025-08-02 16:07:29 +02:00
xbgmsharp
54eefe582d Update migration 202505
- Update monitoring view to with true wind speed
2025-08-02 11:31:32 +02:00
xbgmsharp
d60af8c7b0 Update tests, TimescaleDB: 2.21.1 2025-08-02 10:40:43 +02:00
xbgmsharp
b505c98723 Update README 2025-08-02 10:32:14 +02:00
xbgmsharp
976ea85538 Update logbook tests 2025-07-14 08:56:48 +02:00
xbgmsharp
347af573c2 Update tests versions, timescaledb 2.21.0 2025-07-14 08:56:17 +02:00
xbgmsharp
60ba821af7 Update tests, add stays_ext unit tests 2025-06-22 10:42:33 +02:00
xbgmsharp
9759045b0a Update tests versions, PostgREST 13.0.4 2025-06-22 10:41:33 +02:00
xbgmsharp
a6c351c936 Update web UI front-end to v0.1.0-beta16 2025-06-21 13:00:39 +02:00
11 changed files with 979 additions and 74 deletions

View File

@@ -32,6 +32,7 @@
[![issues - postgsail](https://img.shields.io/github/issues/xbgmsharp/postgsail)](https://github.com/xbgmsharp/postgsail/issues)
[![PRs Welcome](https://img.shields.io/badge/PRs-welcome-brightgreen.svg?style=flat-square)](http://makeapullrequest.com)
![Contributors](https://img.shields.io/github/contributors/xbgmsharp/postgsail?color=dark-green)
[![GitHub Repo stars](https://img.shields.io/github/stars/xbgmsharp/postgsail?style=social)](https://github.com/xbgmsharp/postgsail/stargazers)
[![Test services db, api](https://github.com/xbgmsharp/postgsail/actions/workflows/db-test.yml/badge.svg)](https://github.com/xbgmsharp/postgsail/actions/workflows/db-test.yml)
[![Test services db, api, web](https://github.com/xbgmsharp/postgsail/actions/workflows/frontend-test.yml/badge.svg)](https://github.com/xbgmsharp/postgsail/actions/workflows/frontend-test.yml)

View File

@@ -769,14 +769,14 @@ COMMENT ON FUNCTION
IS 'Create a GeoJSON with a feature Point with the last position and stay details';
-- Update monitoring view to support live moorage in GeoJSON
CREATE VIEW api.monitoring_view WITH (security_invoker=true,security_barrier=true) AS
CREATE OR REPLACE VIEW api.monitoring_view WITH (security_invoker=true,security_barrier=true) AS
SELECT
time AS "time",
(NOW() AT TIME ZONE 'UTC' - time) > INTERVAL '70 MINUTES' as offline,
metrics-> 'environment.water.temperature' AS waterTemperature,
metrics-> 'environment.inside.temperature' AS insideTemperature,
metrics-> 'environment.outside.temperature' AS outsideTemperature,
metrics-> 'environment.wind.speedOverGround' AS windSpeedOverGround,
metrics-> 'environment.wind.speedTrue' AS windSpeedOverGround,
metrics-> 'environment.wind.directionTrue' AS windDirectionTrue,
metrics-> 'environment.inside.relativeHumidity' AS insideHumidity,
metrics-> 'environment.outside.relativeHumidity' AS outsideHumidity,

View File

@@ -0,0 +1,734 @@
---------------------------------------------------------------------------
-- Copyright 2021-2025 Francois Lacroix <xbgmsharp@gmail.com>
-- 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 June/July 2025
--
-- List current database
select current_database();
-- connect to the DB
\c signalk
\echo 'Timing mode is enabled'
\timing
\echo 'Force timezone, just in case'
set timezone to 'UTC';
-- Update plugin upgrade message
UPDATE public.email_templates
SET email_content='Hello __RECIPIENT__,
Please upgrade your postgsail signalk plugin. Make sure you restart your Signalk instance after upgrading. Be sure to contact me if you encounter any issue.'
WHERE "name"='skplugin_upgrade';
-- DROP FUNCTION api.login(text, text);
-- Update api.login, update the connected_at field to the current time
CREATE OR REPLACE FUNCTION api.login(email text, pass text)
RETURNS auth.jwt_token
LANGUAGE plpgsql
SECURITY DEFINER
AS $function$
declare
_role name;
result auth.jwt_token;
app_jwt_secret text;
_email_valid boolean := false;
_email text := email;
_user_id text := null;
_user_disable boolean := false;
headers json := current_setting('request.headers', true)::json;
client_ip text := coalesce(headers->>'x-client-ip', NULL);
begin
-- check email and password
select auth.user_role(email, pass) into _role;
if _role is null then
-- HTTP/403
--raise invalid_password using message = 'invalid user or password';
-- HTTP/401
raise insufficient_privilege using message = 'invalid user or password';
end if;
-- Check if user is disable due to abuse
SELECT preferences['disable'],user_id INTO _user_disable,_user_id
FROM auth.accounts a
WHERE a.email = _email;
IF _user_disable is True then
-- due to the raise, the insert is never committed.
--INSERT INTO process_queue (channel, payload, stored, ref_id)
-- VALUES ('account_disable', _email, now(), _user_id);
RAISE sqlstate 'PT402' using message = 'Account disable, contact us',
detail = 'Quota exceeded',
hint = 'Upgrade your plan';
END IF;
-- Check email_valid and generate OTP
SELECT preferences['email_valid'],user_id INTO _email_valid,_user_id
FROM auth.accounts a
WHERE a.email = _email;
IF _email_valid is null or _email_valid is False THEN
INSERT INTO process_queue (channel, payload, stored, ref_id)
VALUES ('email_otp', _email, now(), _user_id);
END IF;
-- Track IP per user to avoid abuse
--RAISE WARNING 'api.login debug: [%],[%]', client_ip, login.email;
IF client_ip IS NOT NULL THEN
UPDATE auth.accounts a SET
preferences = jsonb_recursive_merge(a.preferences, jsonb_build_object('ip', client_ip)),
connected_at = NOW()
WHERE a.email = login.email;
END IF;
-- Get app_jwt_secret
SELECT value INTO app_jwt_secret
FROM app_settings
WHERE name = 'app.jwt_secret';
--RAISE WARNING 'api.login debug: [%],[%],[%]', app_jwt_secret, _role, login.email;
-- Generate jwt
select jwt.sign(
-- row_to_json(r), ''
-- row_to_json(r)::json, current_setting('app.jwt_secret')::text
row_to_json(r)::json, app_jwt_secret
) as token
from (
select _role as role, login.email as email, -- TODO replace with user_id
-- select _role as role, user_id as uid, -- add support in check_jwt
extract(epoch from now())::integer + 60*60 as exp
) r
into result;
return result;
end;
$function$
;
-- Description
COMMENT ON FUNCTION api.login IS 'Handle user login, returns a JWT token with user role and email.';
-- DROP FUNCTION api.monitoring_history_fn(in text, out jsonb);
-- Update monitoring_history_fn to use custom user settings for metrics
CREATE OR REPLACE FUNCTION api.monitoring_history_fn(time_interval text DEFAULT '24'::text, OUT history_metrics jsonb)
RETURNS jsonb
LANGUAGE plpgsql
AS $function$
DECLARE
bucket_interval interval := '5 minutes';
BEGIN
RAISE NOTICE '-> monitoring_history_fn';
SELECT CASE time_interval
WHEN '24' THEN '5 minutes'
WHEN '48' THEN '2 hours'
WHEN '72' THEN '4 hours'
WHEN '168' THEN '7 hours'
ELSE '5 minutes'
END bucket INTO bucket_interval;
RAISE NOTICE '-> monitoring_history_fn % %', time_interval, bucket_interval;
WITH history_table AS (
SELECT time_bucket(bucket_interval::INTERVAL, mt.time) AS time_bucket,
avg(-- Water Temperature
COALESCE(
mt.metrics->'water'->>'temperature',
mt.metrics->>(md.configuration->>'waterTemperatureKey'),
mt.metrics->>'environment.water.temperature'
)::FLOAT) AS waterTemperature,
avg(-- Inside Temperature
COALESCE(
mt.metrics->'temperature'->>'inside',
mt.metrics->>(md.configuration->>'insideTemperatureKey'),
mt.metrics->>'environment.inside.temperature'
)::FLOAT) AS insideTemperature,
avg(-- Outside Temperature
COALESCE(
mt.metrics->'temperature'->>'outside',
mt.metrics->>(md.configuration->>'outsideTemperatureKey'),
mt.metrics->>'environment.outside.temperature'
)::FLOAT) AS outsideTemperature,
avg(-- Wind Speed True
COALESCE(
mt.metrics->'wind'->>'speed',
mt.metrics->>(md.configuration->>'windSpeedKey'),
mt.metrics->>'environment.wind.speedTrue'
)::FLOAT) AS windSpeedOverGround,
avg(-- Inside Humidity
COALESCE(
mt.metrics->'humidity'->>'inside',
mt.metrics->>(md.configuration->>'insideHumidityKey'),
mt.metrics->>'environment.inside.relativeHumidity',
mt.metrics->>'environment.inside.humidity'
)::FLOAT) AS insideHumidity,
avg(-- Outside Humidity
COALESCE(
mt.metrics->'humidity'->>'outside',
mt.metrics->>(md.configuration->>'outsideHumidityKey'),
mt.metrics->>'environment.outside.relativeHumidity',
mt.metrics->>'environment.outside.humidity'
)::FLOAT) AS outsideHumidity,
avg(-- Outside Pressure
COALESCE(
mt.metrics->'pressure'->>'outside',
mt.metrics->>(md.configuration->>'outsidePressureKey'),
mt.metrics->>'environment.outside.pressure'
)::FLOAT) AS outsidePressure,
avg(--Inside Pressure
COALESCE(
mt.metrics->'pressure'->>'inside',
mt.metrics->>(md.configuration->>'insidePressureKey'),
mt.metrics->>'environment.inside.pressure'
)::FLOAT) AS insidePressure,
avg(-- Battery Charge (State of Charge)
COALESCE(
mt.metrics->'battery'->>'charge',
mt.metrics->>(md.configuration->>'stateOfChargeKey'),
mt.metrics->>'electrical.batteries.House.capacity.stateOfCharge'
)::FLOAT) AS batteryCharge,
avg(-- Battery Voltage
COALESCE(
mt.metrics->'battery'->>'voltage',
mt.metrics->>(md.configuration->>'voltageKey'),
mt.metrics->>'electrical.batteries.House.voltage'
)::FLOAT) AS batteryVoltage,
avg(-- Water Depth
COALESCE(
mt.metrics->'water'->>'depth',
mt.metrics->>(md.configuration->>'depthKey'),
mt.metrics->>'environment.depth.belowTransducer'
)::FLOAT) AS depth
FROM api.metrics mt
JOIN api.metadata md ON md.vessel_id = mt.vessel_id
WHERE mt.time > (NOW() AT TIME ZONE 'UTC' - INTERVAL '1 hours' * time_interval::NUMERIC)
GROUP BY time_bucket
ORDER BY time_bucket asc
)
SELECT jsonb_agg(history_table) INTO history_metrics FROM history_table;
END
$function$
;
-- Description
COMMENT ON FUNCTION api.monitoring_history_fn(in text, out jsonb) IS 'Export metrics from a time period 24h, 48h, 72h, 7d';
-- DROP FUNCTION public.cron_alerts_fn();
-- Update cron_alerts_fn to check for alerts, filters out empty strings (""), so they are not included in the result.
CREATE OR REPLACE FUNCTION public.cron_alerts_fn()
RETURNS void
LANGUAGE plpgsql
AS $function$
DECLARE
alert_rec record;
default_last_metric TIMESTAMPTZ := NOW() - interval '1 day';
last_metric TIMESTAMPTZ;
metric_rec record;
app_settings JSONB;
user_settings JSONB;
alerting JSONB;
_alarms JSONB;
alarms TEXT;
alert_default JSONB := '{
"low_pressure_threshold": 990,
"high_wind_speed_threshold": 30,
"low_water_depth_threshold": 1,
"min_notification_interval": 6,
"high_pressure_drop_threshold": 12,
"low_battery_charge_threshold": 90,
"low_battery_voltage_threshold": 12.5,
"low_water_temperature_threshold": 10,
"low_indoor_temperature_threshold": 7,
"low_outdoor_temperature_threshold": 3
}';
BEGIN
-- Check for new event notification pending update
RAISE NOTICE 'cron_alerts_fn';
FOR alert_rec in
SELECT
a.user_id,a.email,v.vessel_id,
COALESCE((a.preferences->'alert_last_metric')::TEXT, default_last_metric::TEXT) as last_metric,
(alert_default || ( -- Filters out empty strings (""), so they are not included in the result.
SELECT jsonb_object_agg(key, value)
FROM jsonb_each(a.preferences->'alerting')
WHERE value <> '""'
)) as alerting,
(a.preferences->'alarms')::JSONB as alarms,
m.configuration as config
FROM auth.accounts a
LEFT JOIN auth.vessels AS v ON v.owner_email = a.email
LEFT JOIN api.metadata AS m ON m.vessel_id = v.vessel_id
WHERE (a.preferences->'alerting'->'enabled')::boolean = True
AND m.active = True
LOOP
RAISE NOTICE '-> cron_alerts_fn for [%]', alert_rec;
PERFORM set_config('vessel.id', alert_rec.vessel_id, false);
PERFORM set_config('user.email', alert_rec.email, false);
--RAISE WARNING 'public.cron_process_alert_rec_fn() scheduler vessel.id %, user.id', current_setting('vessel.id', false), current_setting('user.id', false);
-- Gather user settings
user_settings := get_user_settings_from_vesselid_fn(alert_rec.vessel_id::TEXT);
RAISE NOTICE '-> cron_alerts_fn checking user_settings [%]', user_settings;
-- Get all metrics from the last last_metric avg by 5 minutes
FOR metric_rec in
SELECT time_bucket('5 minutes', m.time) AS time_bucket,
avg(-- Inside Temperature
COALESCE(
mt.metrics->'temperature'->>'inside',
mt.metrics->>(md.configuration->>'insideTemperatureKey'),
mt.metrics->>'environment.inside.temperature'
)::FLOAT) AS intemp,
avg(-- Wind Speed True
COALESCE(
mt.metrics->'wind'->>'speed',
mt.metrics->>(md.configuration->>'windSpeedKey'),
mt.metrics->>'environment.wind.speedTrue'
)::FLOAT) AS wind,
avg(-- Water Depth
COALESCE(
mt.metrics->'water'->>'depth',
mt.metrics->>(md.configuration->>'depthKey'),
mt.metrics->>'environment.depth.belowTransducer'
)::FLOAT) AS watdepth,
avg(-- Outside Temperature
COALESCE(
m.metrics->'temperature'->>'outside',
m.metrics->>(alert_rec.config->>'outsideTemperatureKey'),
m.metrics->>'environment.outside.temperature'
)::NUMERIC) AS outtemp,
avg(-- Water Temperature
COALESCE(
m.metrics->'water'->>'temperature',
m.metrics->>(alert_rec.config->>'waterTemperatureKey'),
m.metrics->>'environment.water.temperature'
)::NUMERIC) AS wattemp,
avg(-- Outside Pressure
COALESCE(
m.metrics->'pressure'->>'outside',
m.metrics->>(alert_rec.config->>'outsidePressureKey'),
m.metrics->>'environment.outside.pressure'
)::NUMERIC) AS pressure,
avg(-- Battery Voltage
COALESCE(
m.metrics->'battery'->>'voltage',
m.metrics->>(alert_rec.config->>'voltageKey'),
m.metrics->>'electrical.batteries.House.voltage'
)::NUMERIC) AS voltage,
avg(-- Battery Charge (State of Charge)
COALESCE(
m.metrics->'battery'->>'charge',
m.metrics->>(alert_rec.config->>'stateOfChargeKey'),
m.metrics->>'electrical.batteries.House.capacity.stateOfCharge'
)::NUMERIC) AS charge
FROM api.metrics m
WHERE vessel_id = alert_rec.vessel_id
AND m.time >= alert_rec.last_metric::TIMESTAMPTZ
GROUP BY time_bucket
ORDER BY time_bucket ASC LIMIT 100
LOOP
RAISE NOTICE '-> cron_alerts_fn checking metrics [%]', metric_rec;
RAISE NOTICE '-> cron_alerts_fn checking alerting [%]', alert_rec.alerting;
--RAISE NOTICE '-> cron_alerts_fn checking debug [%] [%]', kelvinToCel(metric_rec.intemp), (alert_rec.alerting->'low_indoor_temperature_threshold');
IF metric_rec.intemp IS NOT NULL AND public.kelvintocel(metric_rec.intemp::NUMERIC) < (alert_rec.alerting->'low_indoor_temperature_threshold')::NUMERIC then
RAISE NOTICE '-> cron_alerts_fn checking debug indoor_temp [%]', (alert_rec.alarms->'low_indoor_temperature_threshold'->>'date')::TIMESTAMPTZ;
RAISE NOTICE '-> cron_alerts_fn checking debug indoor_temp [%]', metric_rec.time_bucket::TIMESTAMPTZ;
-- Get latest alarms
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
-- Is alarm in the min_notification_interval time frame
IF (
((_alarms->'low_indoor_temperature_threshold'->>'date') IS NULL) OR
(((_alarms->'low_indoor_temperature_threshold'->>'date')::TIMESTAMPTZ
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
< metric_rec.time_bucket::TIMESTAMPTZ)
) THEN
-- Add alarm
alarms := '{"low_indoor_temperature_threshold": {"value": '|| kelvinToCel(metric_rec.intemp) ||', "date":"' || metric_rec.time_bucket || '"}}';
-- Merge alarms
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
-- Update alarms for user
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
-- Gather user settings
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
SELECT user_settings::JSONB || ('{"alert": "low_outdoor_temperature_threshold value:'|| kelvinToCel(metric_rec.intemp) ||' date:'|| metric_rec.time_bucket ||' "}'::text)::JSONB into user_settings;
-- Send notification
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
-- DEBUG
RAISE NOTICE '-> cron_alerts_fn checking debug low_indoor_temperature_threshold +interval';
END IF;
RAISE NOTICE '-> cron_alerts_fn checking debug low_indoor_temperature_threshold';
END IF;
IF metric_rec.outtemp IS NOT NULL AND public.kelvintocel(metric_rec.outtemp::NUMERIC) < (alert_rec.alerting->>'low_outdoor_temperature_threshold')::NUMERIC then
RAISE NOTICE '-> cron_alerts_fn checking debug outdoor_temp [%]', (alert_rec.alarms->'low_outdoor_temperature_threshold'->>'date')::TIMESTAMPTZ;
RAISE NOTICE '-> cron_alerts_fn checking debug outdoor_temp [%]', metric_rec.time_bucket::TIMESTAMPTZ;
-- Get latest alarms
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
-- Is alarm in the min_notification_interval time frame
IF (
((_alarms->'low_outdoor_temperature_threshold'->>'date') IS NULL) OR
(((_alarms->'low_outdoor_temperature_threshold'->>'date')::TIMESTAMPTZ
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
< metric_rec.time_bucket::TIMESTAMPTZ)
) THEN
-- Add alarm
alarms := '{"low_outdoor_temperature_threshold": {"value": '|| kelvinToCel(metric_rec.outtemp) ||', "date":"' || metric_rec.time_bucket || '"}}';
-- Merge alarms
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
-- Update alarms for user
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
-- Gather user settings
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
SELECT user_settings::JSONB || ('{"alert": "low_outdoor_temperature_threshold value:'|| kelvinToCel(metric_rec.outtemp) ||' date:'|| metric_rec.time_bucket ||' "}'::text)::JSONB into user_settings;
-- Send notification
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
-- DEBUG
RAISE NOTICE '-> cron_alerts_fn checking debug low_outdoor_temperature_threshold +interval';
END IF;
RAISE NOTICE '-> cron_alerts_fn checking debug low_outdoor_temperature_threshold';
END IF;
IF metric_rec.wattemp IS NOT NULL AND public.kelvintocel(metric_rec.wattemp::NUMERIC) < (alert_rec.alerting->>'low_water_temperature_threshold')::NUMERIC then
RAISE NOTICE '-> cron_alerts_fn checking debug water_temp [%]', (alert_rec.alarms->'low_water_temperature_threshold'->>'date')::TIMESTAMPTZ;
RAISE NOTICE '-> cron_alerts_fn checking debug water_temp [%]', metric_rec.time_bucket::TIMESTAMPTZ;
-- Get latest alarms
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
-- Is alarm in the min_notification_interval time frame
IF (
((_alarms->'low_water_temperature_threshold'->>'date') IS NULL) OR
(((_alarms->'low_water_temperature_threshold'->>'date')::TIMESTAMPTZ
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
< metric_rec.time_bucket::TIMESTAMPTZ)
) THEN
-- Add alarm
alarms := '{"low_water_temperature_threshold": {"value": '|| kelvinToCel(metric_rec.wattemp) ||', "date":"' || metric_rec.time_bucket || '"}}';
-- Merge alarms
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
-- Update alarms for user
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
-- Gather user settings
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
SELECT user_settings::JSONB || ('{"alert": "low_water_temperature_threshold value:'|| kelvinToCel(metric_rec.wattemp) ||' date:'|| metric_rec.time_bucket ||' "}'::text)::JSONB into user_settings;
-- Send notification
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
-- DEBUG
RAISE NOTICE '-> cron_alerts_fn checking debug low_water_temperature_threshold +interval';
END IF;
RAISE NOTICE '-> cron_alerts_fn checking debug low_water_temperature_threshold';
END IF;
IF metric_rec.watdepth IS NOT NULL AND metric_rec.watdepth::NUMERIC < (alert_rec.alerting->'low_water_depth_threshold')::NUMERIC then
RAISE NOTICE '-> cron_alerts_fn checking debug water_depth [%]', (alert_rec.alarms->'low_water_depth_threshold'->>'date')::TIMESTAMPTZ;
RAISE NOTICE '-> cron_alerts_fn checking debug water_depth [%]', metric_rec.time_bucket::TIMESTAMPTZ;
-- Get latest alarms
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
-- Is alarm in the min_notification_interval time frame
IF (
((_alarms->'low_water_depth_threshold'->>'date') IS NULL) OR
(((_alarms->'low_water_depth_threshold'->>'date')::TIMESTAMPTZ
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
< metric_rec.time_bucket::TIMESTAMPTZ)
) THEN
-- Add alarm
alarms := '{"low_water_depth_threshold": {"value": '|| metric_rec.watdepth ||', "date":"' || metric_rec.time_bucket || '"}}';
-- Merge alarms
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
-- Update alarms for user
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
-- Gather user settings
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
SELECT user_settings::JSONB || ('{"alert": "low_water_depth_threshold value:'|| ROUND(metric_rec.watdepth,2) ||' date:'|| metric_rec.time_bucket ||' "}'::text)::JSONB into user_settings;
-- Send notification
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
-- DEBUG
RAISE NOTICE '-> cron_alerts_fn checking debug low_water_depth_threshold +interval';
END IF;
RAISE NOTICE '-> cron_alerts_fn checking debug low_water_depth_threshold';
END IF;
if metric_rec.pressure IS NOT NULL AND metric_rec.pressure::NUMERIC < (alert_rec.alerting->'high_pressure_drop_threshold')::NUMERIC then
RAISE NOTICE '-> cron_alerts_fn checking debug pressure [%]', (alert_rec.alarms->'high_pressure_drop_threshold'->>'date')::TIMESTAMPTZ;
RAISE NOTICE '-> cron_alerts_fn checking debug pressure [%]', metric_rec.time_bucket::TIMESTAMPTZ;
-- Get latest alarms
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
-- Is alarm in the min_notification_interval time frame
IF (
((_alarms->'high_pressure_drop_threshold'->>'date') IS NULL) OR
(((_alarms->'high_pressure_drop_threshold'->>'date')::TIMESTAMPTZ
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
< metric_rec.time_bucket::TIMESTAMPTZ)
) THEN
-- Add alarm
alarms := '{"high_pressure_drop_threshold": {"value": '|| metric_rec.pressure ||', "date":"' || metric_rec.time_bucket || '"}}';
-- Merge alarms
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
-- Update alarms for user
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
-- Gather user settings
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
SELECT user_settings::JSONB || ('{"alert": "high_pressure_drop_threshold value:'|| ROUND(metric_rec.pressure,2) ||' date:'|| metric_rec.time_bucket ||' "}'::text)::JSONB into user_settings;
-- Send notification
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
-- DEBUG
RAISE NOTICE '-> cron_alerts_fn checking debug high_pressure_drop_threshold +interval';
END IF;
RAISE NOTICE '-> cron_alerts_fn checking debug high_pressure_drop_threshold';
END IF;
IF metric_rec.wind IS NOT NULL AND metric_rec.wind::NUMERIC > (alert_rec.alerting->'high_wind_speed_threshold')::NUMERIC then
RAISE NOTICE '-> cron_alerts_fn checking debug wind [%]', (alert_rec.alarms->'high_wind_speed_threshold'->>'date')::TIMESTAMPTZ;
RAISE NOTICE '-> cron_alerts_fn checking debug wind [%]', metric_rec.time_bucket::TIMESTAMPTZ;
-- Get latest alarms
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
-- Is alarm in the min_notification_interval time frame
IF (
((_alarms->'high_wind_speed_threshold'->>'date') IS NULL) OR
(((_alarms->'high_wind_speed_threshold'->>'date')::TIMESTAMPTZ
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
< metric_rec.time_bucket::TIMESTAMPTZ)
) THEN
-- Add alarm
alarms := '{"high_wind_speed_threshold": {"value": '|| metric_rec.wind ||', "date":"' || metric_rec.time_bucket || '"}}';
-- Merge alarms
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
-- Update alarms for user
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
-- Gather user settings
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
SELECT user_settings::JSONB || ('{"alert": "high_wind_speed_threshold value:'|| ROUND(metric_rec.wind,2) ||' date:'|| metric_rec.time_bucket ||' "}'::text)::JSONB into user_settings;
-- Send notification
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
-- DEBUG
RAISE NOTICE '-> cron_alerts_fn checking debug high_wind_speed_threshold +interval';
END IF;
RAISE NOTICE '-> cron_alerts_fn checking debug high_wind_speed_threshold';
END IF;
IF metric_rec.voltage IS NOT NULL AND metric_rec.voltage::NUMERIC < (alert_rec.alerting->'low_battery_voltage_threshold')::NUMERIC then
RAISE NOTICE '-> cron_alerts_fn checking debug voltage [%]', (alert_rec.alarms->'low_battery_voltage_threshold'->>'date')::TIMESTAMPTZ;
RAISE NOTICE '-> cron_alerts_fn checking debug voltage [%]', metric_rec.time_bucket::TIMESTAMPTZ;
-- Get latest alarms
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
-- Is alarm in the min_notification_interval time frame
IF (
((_alarms->'low_battery_voltage_threshold'->>'date') IS NULL) OR
(((_alarms->'low_battery_voltage_threshold'->>'date')::TIMESTAMPTZ
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
< metric_rec.time_bucket::TIMESTAMPTZ)
) THEN
-- Add alarm
alarms := '{"low_battery_voltage_threshold": {"value": '|| metric_rec.voltage ||', "date":"' || metric_rec.time_bucket || '"}}';
-- Merge alarms
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
-- Update alarms for user
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
-- Gather user settings
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
SELECT user_settings::JSONB || ('{"alert": "low_battery_voltage_threshold value:'|| ROUND(metric_rec.voltage,2) ||' date:'|| metric_rec.time_bucket ||' "}'::text)::JSONB into user_settings;
-- Send notification
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
-- DEBUG
RAISE NOTICE '-> cron_alerts_fn checking debug low_battery_voltage_threshold +interval';
END IF;
RAISE NOTICE '-> cron_alerts_fn checking debug low_battery_voltage_threshold';
END IF;
IF metric_rec.charge IS NOT NULL AND (metric_rec.charge::NUMERIC*100) < (alert_rec.alerting->'low_battery_charge_threshold')::NUMERIC then
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_battery_charge_threshold'->>'date')::TIMESTAMPTZ;
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', metric_rec.time_bucket::TIMESTAMPTZ;
-- Get latest alarms
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
-- Is alarm in the min_notification_interval time frame
IF (
((_alarms->'low_battery_charge_threshold'->>'date') IS NULL) OR
(((_alarms->'low_battery_charge_threshold'->>'date')::TIMESTAMPTZ
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
< metric_rec.time_bucket::TIMESTAMPTZ)
) THEN
-- Add alarm
alarms := '{"low_battery_charge_threshold": {"value": '|| (metric_rec.charge*100) ||', "date":"' || metric_rec.time_bucket || '"}}';
-- Merge alarms
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
-- Update alarms for user
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
-- Gather user settings
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
SELECT user_settings::JSONB || ('{"alert": "low_battery_charge_threshold value:'|| ROUND(metric_rec.charge::NUMERIC*100,2) ||' date:'|| metric_rec.time_bucket ||' "}'::text)::JSONB into user_settings;
-- Send notification
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
-- DEBUG
RAISE NOTICE '-> cron_alerts_fn checking debug low_battery_charge_threshold +interval';
END IF;
RAISE NOTICE '-> cron_alerts_fn checking debug low_battery_charge_threshold';
END IF;
-- Record last metrics time
SELECT metric_rec.time_bucket INTO last_metric;
END LOOP;
PERFORM api.update_user_preferences_fn('{alert_last_metric}'::TEXT, last_metric::TEXT);
END LOOP;
END;
$function$
;
-- Description
COMMENT ON FUNCTION public.cron_alerts_fn() IS 'init by pg_cron to check for alerts';
-- DROP FUNCTION public.process_pre_logbook_fn(int4);
-- Update process_pre_logbook_fn to detect and avoid logbook we more than 1000NM in less 15h
CREATE OR REPLACE FUNCTION public.process_pre_logbook_fn(_id integer)
RETURNS void
LANGUAGE plpgsql
AS $function$
DECLARE
logbook_rec record;
avg_rec record;
geo_rec record;
_invalid_time boolean;
_invalid_interval boolean;
_invalid_distance boolean;
_invalid_ratio boolean;
count_metric numeric;
previous_stays_id numeric;
current_stays_departed text;
current_stays_id numeric;
current_stays_active boolean;
timebucket boolean;
BEGIN
-- If _id is not NULL
IF _id IS NULL OR _id < 1 THEN
RAISE WARNING '-> process_pre_logbook_fn invalid input %', _id;
RETURN;
END IF;
-- Get the logbook record with all necessary fields exist
SELECT * INTO logbook_rec
FROM api.logbook
WHERE active IS false
AND id = _id
AND _from_lng IS NOT NULL
AND _from_lat IS NOT NULL
AND _to_lng IS NOT NULL
AND _to_lat IS NOT NULL;
-- Ensure the query is successful
IF logbook_rec.vessel_id IS NULL THEN
RAISE WARNING '-> process_pre_logbook_fn invalid logbook %', _id;
RETURN;
END IF;
PERFORM set_config('vessel.id', logbook_rec.vessel_id, false);
--RAISE WARNING 'public.process_logbook_queue_fn() scheduler vessel.id %, user.id', current_setting('vessel.id', false), current_setting('user.id', false);
-- Check if all metrics are within 50meters base on geo loc
count_metric := logbook_metrics_dwithin_fn(logbook_rec._from_time::TEXT, logbook_rec._to_time::TEXT, logbook_rec._from_lng::NUMERIC, logbook_rec._from_lat::NUMERIC);
RAISE NOTICE '-> process_pre_logbook_fn logbook_metrics_dwithin_fn count:[%]', count_metric;
-- Calculate logbook data average and geo
-- Update logbook entry with the latest metric data and calculate data
avg_rec := logbook_update_avg_fn(logbook_rec.id, logbook_rec._from_time::TEXT, logbook_rec._to_time::TEXT);
geo_rec := logbook_update_geom_distance_fn(logbook_rec.id, logbook_rec._from_time::TEXT, logbook_rec._to_time::TEXT);
-- Avoid/ignore/delete logbook stationary movement or time sync issue
-- Check time start vs end
SELECT logbook_rec._to_time::TIMESTAMPTZ < logbook_rec._from_time::TIMESTAMPTZ INTO _invalid_time;
-- Is distance is less than 0.010
SELECT geo_rec._track_distance < 0.010 INTO _invalid_distance;
-- Is duration is less than 100sec
SELECT (logbook_rec._to_time::TIMESTAMPTZ - logbook_rec._from_time::TIMESTAMPTZ) < (100::text||' secs')::interval INTO _invalid_interval;
-- If we have more than 800NM in less 15h
IF geo_rec._track_distance >= 800 AND (logbook_rec._to_time::TIMESTAMPTZ - logbook_rec._from_time::TIMESTAMPTZ) < (15::text||' hours')::interval THEN
_invalid_distance := True;
_invalid_interval := True;
--RAISE NOTICE '-> process_pre_logbook_fn invalid logbook data id [%], _invalid_distance [%], _invalid_interval [%]', logbook_rec.id, _invalid_distance, _invalid_interval;
END IF;
-- If we have less than 20 metrics or less than 0.5NM or less than avg 0.5knts
-- Is within metrics represent more or equal than 60% of the total entry
IF count_metric::NUMERIC <= 20 OR geo_rec._track_distance < 0.5 OR avg_rec.avg_speed < 0.5 THEN
SELECT (count_metric::NUMERIC / avg_rec.count_metric::NUMERIC) >= 0.60 INTO _invalid_ratio;
END IF;
-- if stationary fix data metrics,logbook,stays,moorage
IF _invalid_time IS True OR _invalid_distance IS True
OR _invalid_interval IS True OR count_metric = avg_rec.count_metric
OR _invalid_ratio IS True
OR avg_rec.count_metric <= 3 THEN
RAISE NOTICE '-> process_pre_logbook_fn invalid logbook data id [%], _invalid_time [%], _invalid_distance [%], _invalid_interval [%], count_metric_in_zone [%], count_metric_log [%], _invalid_ratio [%]',
logbook_rec.id, _invalid_time, _invalid_distance, _invalid_interval, count_metric, avg_rec.count_metric, _invalid_ratio;
-- Update metrics status to moored
UPDATE api.metrics
SET status = 'moored'
WHERE time >= logbook_rec._from_time::TIMESTAMPTZ
AND time <= logbook_rec._to_time::TIMESTAMPTZ
AND vessel_id = current_setting('vessel.id', false);
-- Update logbook
UPDATE api.logbook
SET notes = 'invalid logbook data, stationary need to fix metrics?'
WHERE vessel_id = current_setting('vessel.id', false)
AND id = logbook_rec.id;
-- Get related stays
SELECT id,departed,active INTO current_stays_id,current_stays_departed,current_stays_active
FROM api.stays s
WHERE s.vessel_id = current_setting('vessel.id', false)
AND s.arrived = logbook_rec._to_time::TIMESTAMPTZ;
-- Update related stays
UPDATE api.stays s
SET notes = 'invalid stays data, stationary need to fix metrics?'
WHERE vessel_id = current_setting('vessel.id', false)
AND arrived = logbook_rec._to_time::TIMESTAMPTZ;
-- Find previous stays
SELECT id INTO previous_stays_id
FROM api.stays s
WHERE s.vessel_id = current_setting('vessel.id', false)
AND s.arrived < logbook_rec._to_time::TIMESTAMPTZ
ORDER BY s.arrived DESC LIMIT 1;
-- Update previous stays with the departed time from current stays
-- and set the active state from current stays
UPDATE api.stays
SET departed = current_stays_departed::TIMESTAMPTZ,
active = current_stays_active
WHERE vessel_id = current_setting('vessel.id', false)
AND id = previous_stays_id;
-- Clean up, remove invalid logbook and stay entry
DELETE FROM api.logbook WHERE id = logbook_rec.id;
RAISE WARNING '-> process_pre_logbook_fn delete invalid logbook [%]', logbook_rec.id;
DELETE FROM api.stays WHERE id = current_stays_id;
RAISE WARNING '-> process_pre_logbook_fn delete invalid stays [%]', current_stays_id;
RETURN;
END IF;
--IF (logbook_rec.notes IS NULL) THEN -- run one time only
-- -- If duration is over 24h or number of entry is over 400, check for stays and potential multiple logs with stationary location
-- IF (logbook_rec._to_time::TIMESTAMPTZ - logbook_rec._from_time::TIMESTAMPTZ) > INTERVAL '24 hours'
-- OR avg_rec.count_metric > 400 THEN
-- timebucket := public.logbook_metrics_timebucket_fn('15 minutes'::TEXT, logbook_rec.id, logbook_rec._from_time::TIMESTAMPTZ, logbook_rec._to_time::TIMESTAMPTZ);
-- -- If true exit current process as the current logbook need to be re-process.
-- IF timebucket IS True THEN
-- RETURN;
-- END IF;
-- ELSE
-- timebucket := public.logbook_metrics_timebucket_fn('5 minutes'::TEXT, logbook_rec.id, logbook_rec._from_time::TIMESTAMPTZ, logbook_rec._to_time::TIMESTAMPTZ);
-- -- If true exit current process as the current logbook need to be re-process.
-- IF timebucket IS True THEN
-- RETURN;
-- END IF;
-- END IF;
--END IF;
-- Add logbook entry to process queue for later processing
INSERT INTO process_queue (channel, payload, stored, ref_id)
VALUES ('new_logbook', logbook_rec.id, NOW(), current_setting('vessel.id', true));
END;
$function$
;
COMMENT ON FUNCTION public.process_pre_logbook_fn(int4) IS 'Detect/Avoid/ignore/delete logbook stationary movement or time sync issue';
-- Revoke security definer
--ALTER FUNCTION api.update_logbook_observations_fn(_id integer, observations text) SECURITY INVOKER;
--ALTER FUNCTION api.delete_logbook_fn(_id integer) SECURITY INVOKER;
ALTER FUNCTION api.merge_logbook_fn(_id integer, _id integer) SECURITY INVOKER;
GRANT DELETE ON TABLE public.process_queue TO user_role;
GRANT SELECT ON ALL TABLES IN SCHEMA api TO user_role;
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA api TO user_role;
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public TO user_role;
GRANT UPDATE (status) ON api.metrics TO user_role;
GRANT UPDATE ON api.logbook TO user_role;
DROP POLICY IF EXISTS api_user_role ON api.metrics;
CREATE POLICY api_user_role ON api.metrics TO user_role
USING (vessel_id = current_setting('vessel.id', false))
WITH CHECK (vessel_id = current_setting('vessel.id', false));
-- Update version
UPDATE public.app_settings
SET value='0.9.3'
WHERE "name"='app.version';
--\c postgres
--UPDATE cron.job SET username = 'scheduler'; -- Update to scheduler
--UPDATE cron.job SET username = current_user WHERE jobname = 'cron_vacuum'; -- Update to superuser for vacuum permissions
--UPDATE cron.job SET username = current_user WHERE jobname = 'job_run_details_cleanup';

View File

@@ -1 +1 @@
0.9.2
0.9.3

View File

@@ -22,12 +22,26 @@ SELECT v.vessel_id as "vessel_id" FROM auth.vessels v WHERE v.owner_email = 'dem
--\echo :"vessel_id"
SELECT set_config('vessel.id', :'vessel_id', false) IS NOT NULL as vessel_id;
-- Delete logbook for user
-- Count logbook for user
\echo 'logbook'
SELECT count(*) FROM api.logbook WHERE vessel_id = current_setting('vessel.id', false);
\echo 'logbook'
-- track_geom and track_geojson are now dynamic from mobilitydb
SELECT name,_from_time IS NOT NULL AS _from_time, _to_time IS NOT NULL AS _to_time, trajectory(trip) AS track_geom, distance,duration,avg_speed,max_speed,max_wind_speed,notes,extra FROM api.logbook WHERE vessel_id = current_setting('vessel.id', false) ORDER BY id ASC;
SELECT name,_from_time IS NOT NULL AS _from_time_not_null, _to_time IS NOT NULL AS _to_time_not_null, trajectory(trip) AS track_geom, distance,duration,avg_speed,max_speed,max_wind_speed,notes,extra FROM api.logbook WHERE vessel_id = current_setting('vessel.id', false) ORDER BY id ASC;
--
-- user_role
SET ROLE user_role;
\echo 'ROLE user_role current_setting'
SELECT set_config('vessel.id', :'vessel_id', false) IS NOT NULL as vessel_id;
-- Count logbook for user
\echo 'logbook'
SELECT count(*) FROM api.logbook;
\echo 'logbook'
-- track_geom and track_geojson are now dynamic from mobilitydb
SELECT name,_from_time IS NOT NULL AS _from_time_not_null, _to_time IS NOT NULL AS _to_time_not_null, trajectory(trip) AS track_geom, distance,duration,avg_speed,max_speed,max_wind_speed,notes,extra FROM api.logbook ORDER BY id ASC;
-- Delete logbook for user
\echo 'Delete logbook for user kapla'

View File

@@ -17,54 +17,113 @@ logbook
count | 4
logbook
-[ RECORD 1 ]--+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
name | patch log name 3
_from_time | t
_to_time | t
track_geom | 0102000020E61000001A000000B0DEBBE0E68737404DA938FBF0094E4020D26F5F0786374030BB270F0B094E400C6E7ED60F843740AA60545227084E40D60FC48C03823740593CE27D42074E407B39D9F322803740984C158C4A064E4091ED7C3F357E3740898BB63D54054E40A8A1208B477C37404BA3DC9059044E404C5CB4EDA17A3740C4F856115B034E40A9A44E4013793740D8F0F44A59024E40E4839ECDAA773740211FF46C56014E405408D147067637408229F03B73004E40787AA52C43743740F90FE9B7AFFF4D40F8098D4D18723740C217265305FF4D4084E82303537037409A2D464AA0FE4D4022474DCE636F37402912396A72FE4D408351499D806E374088CFB02B40FE4D4076711B0DE06D3740B356C7040FFE4D404EAC66B0BC6E374058A835CD3BFE4D40D7A3703D0A6F3740D3E10EC15EFE4D4087602F277B6E3740A779C7293AFE4D402063EE5A426E3740B5A679C729FE4D40381DEE10EC6D37409ECA7C1A0AFE4D40E2C46A06CB6B37400A43F7BF36FD4D4075931804566E3740320BDAD125FD4D409A2D464AA06E37404A5658830AFD4D40029A081B9E6E37404A5658830AFD4D40
distance | 7.6447
duration | PT27M
avg_speed | 3.6357142857142852
max_speed | 6.1
max_wind_speed | 22.1
notes | new log note 3
extra | {"tags": ["tag_name"], "metrics": {"propulsion.main.runTime": "PT10S"}, "observations": {"seaState": -1, "visibility": -1, "cloudCoverage": 1}, "avg_wind_speed": 14.549999999999999}
-[ RECORD 2 ]--+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
name | Norra hamnen to Ekenäs
_from_time | t
_to_time | t
track_geom | 0102000020E610000013000000029A081B9E6E37404A5658830AFD4D404806A6C0EF6C3740DA1B7C6132FD4D40FE65F7E461693740226C787AA5FC4D407DD3E10EC1663740B29DEFA7C6FB4D40898BB63D5465374068479724BCFA4D409A5271F6E1633740B6847CD0B3F94D40431CEBE236623740E9263108ACF84D402C6519E2585F37407E678EBFC7F74D4096218E75715B374027C5B45C23F74D402AA913D044583740968DE1C46AF64D405AF5B9DA8A5537407BEF829B9FF54D407449C2ABD253374086C954C1A8F44D407D1A0AB278543740F2B0506B9AF34D409D11A5BDC15737406688635DDCF24D4061C3D32B655937402CAF6F3ADCF14D408988888888583740B3319C58CDF04D4021FAC8C0145837408C94405DB7EF4D40B8F9593F105B37403DC0804BEDEE4D40DE4C5FE2A25D3740AE47E17A14EE4D40
distance | 8.8968
duration | PT20M
avg_speed | 5.4523809523809526
max_speed | 6.5
max_wind_speed | 37.2
notes |
extra | {"metrics": {"propulsion.main.runTime": "PT11S"}, "observations": {"seaState": -1, "visibility": -1, "cloudCoverage": -1}, "avg_wind_speed": 10.476190476190478}
-[ RECORD 3 ]--+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
name | Tropics Zone
_from_time | t
_to_time | t
track_geom | 0102000020E610000002000000A4E85E0D58934FC000DC509B80052C40BC069B43D64553C090510727F3BD2940
distance | 123
duration |
avg_speed |
max_speed |
max_wind_speed |
notes |
extra |
-[ RECORD 4 ]--+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
name | Alaska Zone
_from_time | t
_to_time | t
track_geom | 0102000020E610000002000000FDB11ED079F261C090C47F1861B84D40D3505124540B63C09C091C1C8D4A4C40
distance | 1234
duration |
avg_speed |
max_speed |
max_wind_speed |
notes |
extra |
-[ RECORD 1 ]-------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
name | patch log name 3
_from_time_not_null | t
_to_time_not_null | t
track_geom | 0102000020E61000001A000000B0DEBBE0E68737404DA938FBF0094E4020D26F5F0786374030BB270F0B094E400C6E7ED60F843740AA60545227084E40D60FC48C03823740593CE27D42074E407B39D9F322803740984C158C4A064E4091ED7C3F357E3740898BB63D54054E40A8A1208B477C37404BA3DC9059044E404C5CB4EDA17A3740C4F856115B034E40A9A44E4013793740D8F0F44A59024E40E4839ECDAA773740211FF46C56014E405408D147067637408229F03B73004E40787AA52C43743740F90FE9B7AFFF4D40F8098D4D18723740C217265305FF4D4084E82303537037409A2D464AA0FE4D4022474DCE636F37402912396A72FE4D408351499D806E374088CFB02B40FE4D4076711B0DE06D3740B356C7040FFE4D404EAC66B0BC6E374058A835CD3BFE4D40D7A3703D0A6F3740D3E10EC15EFE4D4087602F277B6E3740A779C7293AFE4D402063EE5A426E3740B5A679C729FE4D40381DEE10EC6D37409ECA7C1A0AFE4D40E2C46A06CB6B37400A43F7BF36FD4D4075931804566E3740320BDAD125FD4D409A2D464AA06E37404A5658830AFD4D40029A081B9E6E37404A5658830AFD4D40
distance | 7.6447
duration | PT27M
avg_speed | 3.6357142857142852
max_speed | 6.1
max_wind_speed | 22.1
notes | new log note 3
extra | {"tags": ["tag_name"], "metrics": {"propulsion.main.runTime": "PT10S"}, "observations": {"seaState": -1, "visibility": -1, "cloudCoverage": 1}, "avg_wind_speed": 14.549999999999999}
-[ RECORD 2 ]-------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
name | Norra hamnen to Ekenäs
_from_time_not_null | t
_to_time_not_null | t
track_geom | 0102000020E610000013000000029A081B9E6E37404A5658830AFD4D404806A6C0EF6C3740DA1B7C6132FD4D40FE65F7E461693740226C787AA5FC4D407DD3E10EC1663740B29DEFA7C6FB4D40898BB63D5465374068479724BCFA4D409A5271F6E1633740B6847CD0B3F94D40431CEBE236623740E9263108ACF84D402C6519E2585F37407E678EBFC7F74D4096218E75715B374027C5B45C23F74D402AA913D044583740968DE1C46AF64D405AF5B9DA8A5537407BEF829B9FF54D407449C2ABD253374086C954C1A8F44D407D1A0AB278543740F2B0506B9AF34D409D11A5BDC15737406688635DDCF24D4061C3D32B655937402CAF6F3ADCF14D408988888888583740B3319C58CDF04D4021FAC8C0145837408C94405DB7EF4D40B8F9593F105B37403DC0804BEDEE4D40DE4C5FE2A25D3740AE47E17A14EE4D40
distance | 8.8968
duration | PT20M
avg_speed | 5.4523809523809526
max_speed | 6.5
max_wind_speed | 37.2
notes |
extra | {"metrics": {"propulsion.main.runTime": "PT11S"}, "observations": {"seaState": -1, "visibility": -1, "cloudCoverage": -1}, "avg_wind_speed": 10.476190476190478}
-[ RECORD 3 ]-------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
name | Tropics Zone
_from_time_not_null | t
_to_time_not_null | t
track_geom | 0102000020E610000002000000A4E85E0D58934FC000DC509B80052C40BC069B43D64553C090510727F3BD2940
distance | 123
duration |
avg_speed |
max_speed |
max_wind_speed |
notes |
extra |
-[ RECORD 4 ]-------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
name | Alaska Zone
_from_time_not_null | t
_to_time_not_null | t
track_geom | 0102000020E610000002000000FDB11ED079F261C090C47F1861B84D40D3505124540B63C09C091C1C8D4A4C40
distance | 1234
duration |
avg_speed |
max_speed |
max_wind_speed |
notes |
extra |
SET
ROLE user_role current_setting
-[ RECORD 1 ]
vessel_id | t
logbook
-[ RECORD 1 ]
count | 4
logbook
-[ RECORD 1 ]-------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
name | patch log name 3
_from_time_not_null | t
_to_time_not_null | t
track_geom | 0102000020E61000001A000000B0DEBBE0E68737404DA938FBF0094E4020D26F5F0786374030BB270F0B094E400C6E7ED60F843740AA60545227084E40D60FC48C03823740593CE27D42074E407B39D9F322803740984C158C4A064E4091ED7C3F357E3740898BB63D54054E40A8A1208B477C37404BA3DC9059044E404C5CB4EDA17A3740C4F856115B034E40A9A44E4013793740D8F0F44A59024E40E4839ECDAA773740211FF46C56014E405408D147067637408229F03B73004E40787AA52C43743740F90FE9B7AFFF4D40F8098D4D18723740C217265305FF4D4084E82303537037409A2D464AA0FE4D4022474DCE636F37402912396A72FE4D408351499D806E374088CFB02B40FE4D4076711B0DE06D3740B356C7040FFE4D404EAC66B0BC6E374058A835CD3BFE4D40D7A3703D0A6F3740D3E10EC15EFE4D4087602F277B6E3740A779C7293AFE4D402063EE5A426E3740B5A679C729FE4D40381DEE10EC6D37409ECA7C1A0AFE4D40E2C46A06CB6B37400A43F7BF36FD4D4075931804566E3740320BDAD125FD4D409A2D464AA06E37404A5658830AFD4D40029A081B9E6E37404A5658830AFD4D40
distance | 7.6447
duration | PT27M
avg_speed | 3.6357142857142852
max_speed | 6.1
max_wind_speed | 22.1
notes | new log note 3
extra | {"tags": ["tag_name"], "metrics": {"propulsion.main.runTime": "PT10S"}, "observations": {"seaState": -1, "visibility": -1, "cloudCoverage": 1}, "avg_wind_speed": 14.549999999999999}
-[ RECORD 2 ]-------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
name | Norra hamnen to Ekenäs
_from_time_not_null | t
_to_time_not_null | t
track_geom | 0102000020E610000013000000029A081B9E6E37404A5658830AFD4D404806A6C0EF6C3740DA1B7C6132FD4D40FE65F7E461693740226C787AA5FC4D407DD3E10EC1663740B29DEFA7C6FB4D40898BB63D5465374068479724BCFA4D409A5271F6E1633740B6847CD0B3F94D40431CEBE236623740E9263108ACF84D402C6519E2585F37407E678EBFC7F74D4096218E75715B374027C5B45C23F74D402AA913D044583740968DE1C46AF64D405AF5B9DA8A5537407BEF829B9FF54D407449C2ABD253374086C954C1A8F44D407D1A0AB278543740F2B0506B9AF34D409D11A5BDC15737406688635DDCF24D4061C3D32B655937402CAF6F3ADCF14D408988888888583740B3319C58CDF04D4021FAC8C0145837408C94405DB7EF4D40B8F9593F105B37403DC0804BEDEE4D40DE4C5FE2A25D3740AE47E17A14EE4D40
distance | 8.8968
duration | PT20M
avg_speed | 5.4523809523809526
max_speed | 6.5
max_wind_speed | 37.2
notes |
extra | {"metrics": {"propulsion.main.runTime": "PT11S"}, "observations": {"seaState": -1, "visibility": -1, "cloudCoverage": -1}, "avg_wind_speed": 10.476190476190478}
-[ RECORD 3 ]-------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
name | Tropics Zone
_from_time_not_null | t
_to_time_not_null | t
track_geom | 0102000020E610000002000000A4E85E0D58934FC000DC509B80052C40BC069B43D64553C090510727F3BD2940
distance | 123
duration |
avg_speed |
max_speed |
max_wind_speed |
notes |
extra |
-[ RECORD 4 ]-------+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
name | Alaska Zone
_from_time_not_null | t
_to_time_not_null | t
track_geom | 0102000020E610000002000000FDB11ED079F261C090C47F1861B84D40D3505124540B63C09C091C1C8D4A4C40
distance | 1234
duration |
avg_speed |
max_speed |
max_wind_speed |
notes |
extra |
Delete logbook for user kapla
-[ RECORD 1 ]-----+--

47
tests/sql/stays_ext.sql Normal file
View File

@@ -0,0 +1,47 @@
---------------------------------------------------------------------------
-- Listing
--
-- List current database
select current_database();
-- connect to the DB
\c signalk
-- output display format
\x on
SELECT count(*) as count_eq_0 FROM api.stays_ext m;
SELECT v.vessel_id as "vessel_id" FROM auth.vessels v WHERE v.owner_email = 'demo+kapla@openplotter.cloud' \gset
--\echo :"vessel_id"
SELECT set_config('vessel.id', :'vessel_id', false) IS NOT NULL as vessel_id;
-- user_role
SET ROLE user_role;
\echo 'api.stays details'
SELECT vessel_id IS NOT NULL AS vessel_id_not_null, m.name IS NOT NULL AS name_not_null FROM api.stays AS m WHERE active IS False ORDER BY m.name ASC;
-- Upsert image on stays_ext table
\echo 'api.stays_ext set image/image_b64'
INSERT INTO api.stays_ext (vessel_id, stay_id, image_b64)
VALUES (current_setting('vessel.id', false), 1, 'iVBORw0KGgoAAAANSUhEUgAAAMgAAAAyCAIAAACWMwO2AAABNklEQVR4nO3bwY6CMBiF0XYy7//KzIKk6VBjiMMNk59zVljRIH6WsrBv29bgal93HwA1CYsIYREhLCKERYSwiBAWEcIiQlhECIsIYREhLCKERYSwiBAWEcIiQlhECIsIYREhLCK+7z6A/6j33lq75G8m')
ON CONFLICT (stay_id) DO UPDATE
SET image_b64 = EXCLUDED.image_b64;
-- Ensure image_updated_at on metadata_ext table is updated by trigger
\echo 'api.stays_ext get image_updated_at'
SELECT image_b64 IS NULL AS image_b64_is_null,image IS NOT NULL AS image_not_null,image_updated_at IS NOT NULL AS image_updated_at_not_null FROM api.metadata_ext; --WHERE vessel_id = current_setting('vessel.id', false);
-- vessel_role
SET ROLE vessel_role;
\echo 'api.stays_ext'
SELECT vessel_id IS NOT NULL AS vessel_id_not_null, stay_id FROM api.stays_ext;
-- api_anonymous
SET ROLE api_anonymous;
\echo 'api_anonymous get stays image'
SELECT api.stays_image(current_setting('vessel.id', false), 1) IS NOT NULL AS stays_image_not_null;

View File

@@ -0,0 +1,37 @@
current_database
------------------
signalk
(1 row)
You are now connected to database "signalk" as user "username".
Expanded display is on.
-[ RECORD 1 ]-
count_eq_0 | 0
-[ RECORD 1 ]
vessel_id | t
SET
api.stays details
-[ RECORD 1 ]------+--
vessel_id_not_null | t
name_not_null | t
-[ RECORD 2 ]------+--
vessel_id_not_null | t
name_not_null | t
api.stays_ext set image/image_b64
INSERT 0 1
api.stays_ext get image_updated_at
-[ RECORD 1 ]-------------+--
image_b64_is_null | f
image_not_null | t
image_updated_at_not_null | t
SET
api.stays_ext
SET
api_anonymous get stays image
-[ RECORD 1 ]--------+--
stays_image_not_null | t

View File

@@ -5,8 +5,8 @@
You are now connected to database "signalk" as user "username".
Expanded display is on.
-[ RECORD 1 ]--+-------------------------------
server_version | 16.9 (Debian 16.9-1.pgdg120+1)
-[ RECORD 1 ]--+--------------------------------
server_version | 16.10 (Debian 16.10-1.pgdg12+1)
-[ RECORD 1 ]--------+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
postgis_full_version | POSTGIS="3.5.3 aab5f55" [EXTENSION] PGSQL="160" GEOS="3.11.1-CAPI-1.17.1" PROJ="9.1.1 NETWORK_ENABLED=OFF URL_ENDPOINT=https://cdn.proj.org USER_WRITABLE_DIRECTORY=/var/lib/postgresql/.local/share/proj DATABASE_PATH=/usr/share/proj/proj.db" (compiled against PROJ 9.1.1) LIBXML="2.9.14" LIBJSON="0.16" LIBPROTOBUF="1.4.1" WAGYU="0.5.0 (Internal)"
@@ -58,7 +58,7 @@ Schema | public
Description | PostGIS geometry and geography spatial types and functions
-[ RECORD 10 ]-------------------------------------------------------------------------------------
Name | timescaledb
Version | 2.20.3
Version | 2.21.3
Schema | public
Description | Enables scalable inserts and complex queries for time-series data (Community Edition)
-[ RECORD 11 ]-------------------------------------------------------------------------------------
@@ -116,14 +116,14 @@ laninline | 13566
lanvalidator | 13567
lanacl |
-[ RECORD 5 ]-+-----------
oid | 18245
oid | 18251
lanname | plpython3u
lanowner | 10
lanispl | t
lanpltrusted | t
lanplcallfoid | 18242
laninline | 18243
lanvalidator | 18244
lanplcallfoid | 18248
laninline | 18249
lanvalidator | 18250
lanacl |
-[ RECORD 1 ]+-----------
@@ -706,15 +706,15 @@ with_check | false
-[ RECORD 49 ]-----------------------------------------------------------------------------------------------------------------------------
schemaname | api
tablename | metrics
policyname | api_user_role
policyname | api_vessel_role
permissive | PERMISSIVE
roles | {user_role}
roles | {vessel_role}
cmd | ALL
qual | (vessel_id = current_setting('vessel.id'::text, false))
with_check | false
with_check | (vessel_id = current_setting('vessel.id'::text, false))
-[ RECORD 50 ]-----------------------------------------------------------------------------------------------------------------------------
schemaname | api
tablename | metrics
tablename | metadata
policyname | api_vessel_role
permissive | PERMISSIVE
roles | {vessel_role}
@@ -724,15 +724,15 @@ with_check | (vessel_id = current_setting('vessel.id'::text, false))
-[ RECORD 51 ]-----------------------------------------------------------------------------------------------------------------------------
schemaname | api
tablename | metadata
policyname | api_vessel_role
policyname | api_user_role
permissive | PERMISSIVE
roles | {vessel_role}
roles | {user_role}
cmd | ALL
qual | (vessel_id = current_setting('vessel.id'::text, false))
with_check | (vessel_id = current_setting('vessel.id'::text, false))
-[ RECORD 52 ]-----------------------------------------------------------------------------------------------------------------------------
schemaname | api
tablename | metadata
tablename | metrics
policyname | api_user_role
permissive | PERMISSIVE
roles | {user_role}
@@ -755,13 +755,13 @@ overpass_py_fn | {"name": "Port de la Ginesta", "type": "multipolygon", "leisure
-[ RECORD 1 ]--+---------------------------------------------------------------------------------------------------------------
overpass_py_fn | {"name": "Norra hamnen", "leisure": "marina", "seamark:type": "harbour", "seamark:harbour:category": "marina"}
-[ RECORD 1 ]----------------------------------------------------------------------------------------------------------------------------------------------------------------------
versions_fn | {"api_version" : "0.9.2", "sys_version" : "PostgreSQL 16.9", "mobilitydb" : "1.2.0", "timescaledb" : "2.20.3", "postgis" : "3.5.3", "postgrest" : "PostgREST 13.0.2"}
-[ RECORD 1 ]-----------------------------------------------------------------------------------------------------------------------------------------------------------------------
versions_fn | {"api_version" : "0.9.3", "sys_version" : "PostgreSQL 16.10", "mobilitydb" : "1.2.0", "timescaledb" : "2.21.3", "postgis" : "3.5.3", "postgrest" : "PostgREST 13.0.4"}
-[ RECORD 1 ]-----------------
api_version | 0.9.2
sys_version | PostgreSQL 16.9
timescaledb | 2.20.3
api_version | 0.9.3
sys_version | PostgreSQL 16.10
timescaledb | 2.21.3
postgis | 3.5.3
postgrest | PostgREST 13.0.2
postgrest | PostgREST 13.0.4

View File

@@ -139,6 +139,19 @@ else
exit
fi
# Stays extended unit tests
psql ${PGSAIL_DB_URI} < sql/stays_ext.sql > output/stays_ext.sql.output
diff sql/stays_ext.sql.output output/stays_ext.sql.output > /dev/null
#diff -u sql/stays_ext.sql.output output/stays_ext.sql.output | wc -l
#echo 0
if [ $? -eq 0 ]; then
echo OK
else
echo SQL stays_ext.sql FAILED
diff -u sql/stays_ext.sql.output output/stays_ext.sql.output
exit 1
fi
# Summary unit tests
psql ${PGSAIL_DB_URI} < sql/summary.sql > output/summary.sql.output
diff sql/summary.sql.output output/summary.sql.output > /dev/null