mirror of
https://github.com/xbgmsharp/postgsail.git
synced 2025-09-17 19:27:49 +00:00
Compare commits
27 Commits
Author | SHA1 | Date | |
---|---|---|---|
![]() |
b150d9706f | ||
![]() |
813460da7b | ||
![]() |
813b8088f3 | ||
![]() |
f90911c523 | ||
![]() |
790bbb671c | ||
![]() |
5455d8246f | ||
![]() |
95d24c538d | ||
![]() |
57799c9ee4 | ||
![]() |
437bfd0252 | ||
![]() |
dcceab2551 | ||
![]() |
cdc2e4e55c | ||
![]() |
76bbe29567 | ||
![]() |
36b8eece52 | ||
![]() |
a5436479cf | ||
![]() |
23ea3bd0d8 | ||
![]() |
826566e097 | ||
![]() |
f942076cc2 | ||
![]() |
8dba0c21b6 | ||
![]() |
a96160ef15 | ||
![]() |
ccf91bb832 | ||
![]() |
b9993ed28f | ||
![]() |
0e5e619625 | ||
![]() |
294a60d13a | ||
![]() |
b6587b1287 | ||
![]() |
74512d0bf3 | ||
![]() |
322a479b4f | ||
![]() |
c5cba6a59f |
@@ -38,6 +38,8 @@ postgsail-telegram-bot:
|
|||||||
- Offline mode.
|
- Offline mode.
|
||||||
- Low Bandwidth mode.
|
- Low Bandwidth mode.
|
||||||
- Awesome statistics and graphs.
|
- Awesome statistics and graphs.
|
||||||
|
- Create and manage your own dashboards.
|
||||||
|
- Windy PWS (Personal Weather Station).
|
||||||
- Anything missing? just ask!
|
- Anything missing? just ask!
|
||||||
|
|
||||||
## Context
|
## Context
|
||||||
|
2
frontend
2
frontend
Submodule frontend updated: 7ca5656336...83cb839c65
@@ -387,7 +387,7 @@ BEGIN
|
|||||||
PERFORM grafana_py_fn(data_rec.name, data_rec.vessel_id, data_rec.owner_email, app_settings);
|
PERFORM grafana_py_fn(data_rec.name, data_rec.vessel_id, data_rec.owner_email, app_settings);
|
||||||
-- Gather user settings
|
-- Gather user settings
|
||||||
user_settings := get_user_settings_from_vesselid_fn(data_rec.vessel_id::TEXT);
|
user_settings := get_user_settings_from_vesselid_fn(data_rec.vessel_id::TEXT);
|
||||||
RAISE DEBUG '-> DEBUG cron_process_grafana_fn get_user_settings_from_vesselid_fn [%]', user_settings;
|
--RAISE DEBUG '-> DEBUG cron_process_grafana_fn get_user_settings_from_vesselid_fn [%]', user_settings;
|
||||||
-- add user in keycloak
|
-- add user in keycloak
|
||||||
PERFORM keycloak_auth_py_fn(data_rec.vessel_id, user_settings, app_settings);
|
PERFORM keycloak_auth_py_fn(data_rec.vessel_id, user_settings, app_settings);
|
||||||
-- Send notification
|
-- Send notification
|
||||||
@@ -406,6 +406,97 @@ COMMENT ON FUNCTION
|
|||||||
public.cron_process_grafana_fn
|
public.cron_process_grafana_fn
|
||||||
IS 'init by pg_cron to check for new vessel pending grafana provisioning, if so perform grafana_py_fn';
|
IS 'init by pg_cron to check for new vessel pending grafana provisioning, if so perform grafana_py_fn';
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION public.cron_process_windy_fn() RETURNS void AS $$
|
||||||
|
DECLARE
|
||||||
|
windy_rec record;
|
||||||
|
default_last_metric TIMESTAMPTZ := NOW() - interval '1 day';
|
||||||
|
last_metric TIMESTAMPTZ;
|
||||||
|
metric_rec record;
|
||||||
|
windy_metric jsonb;
|
||||||
|
app_settings jsonb;
|
||||||
|
user_settings jsonb;
|
||||||
|
windy_pws jsonb;
|
||||||
|
BEGIN
|
||||||
|
-- Check for new observations pending update
|
||||||
|
RAISE NOTICE 'cron_windy_fn';
|
||||||
|
-- Gather url from app settings
|
||||||
|
app_settings := get_app_settings_fn();
|
||||||
|
-- Find users with Windy active and with an active vessel
|
||||||
|
-- Map account id to Windy Station ID
|
||||||
|
FOR windy_rec in
|
||||||
|
SELECT
|
||||||
|
a.id,a.email,v.vessel_id,v.name,
|
||||||
|
COALESCE((a.preferences->'windy_last_metric')::TEXT, default_last_metric::TEXT) as last_metric
|
||||||
|
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->'public_windy')::boolean = True
|
||||||
|
AND m.active = True
|
||||||
|
LOOP
|
||||||
|
RAISE NOTICE '-> cron_windy_fn for [%]', windy_rec;
|
||||||
|
PERFORM set_config('vessel.id', windy_rec.vessel_id, false);
|
||||||
|
--RAISE WARNING 'public.cron_process_windy_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(windy_rec.vessel_id::TEXT);
|
||||||
|
RAISE NOTICE '-> cron_windy_fn checking user_settings [%]', user_settings;
|
||||||
|
-- Get all metrics from the last windy_last_metric avg by 5 minutes
|
||||||
|
-- TODO json_agg to send all data in once, but issue with py jsonb transformation decimal.
|
||||||
|
FOR metric_rec in
|
||||||
|
SELECT time_bucket('5 minutes', m.time) AS time_bucket,
|
||||||
|
avg((m.metrics->'environment.outside.temperature')::numeric) AS temperature,
|
||||||
|
avg((m.metrics->'environment.outside.pressure')::numeric) AS pressure,
|
||||||
|
avg((m.metrics->'environment.outside.relativeHumidity')::numeric) AS rh,
|
||||||
|
avg((m.metrics->'environment.wind.directionTrue')::numeric) AS winddir,
|
||||||
|
avg((m.metrics->'environment.wind.speedTrue')::numeric) AS wind,
|
||||||
|
max((m.metrics->'environment.wind.speedTrue')::numeric) AS gust,
|
||||||
|
last(latitude, time) AS lat,
|
||||||
|
last(longitude, time) AS lng
|
||||||
|
FROM api.metrics m
|
||||||
|
WHERE vessel_id = windy_rec.vessel_id
|
||||||
|
AND m.time >= windy_rec.last_metric::TIMESTAMPTZ
|
||||||
|
GROUP BY time_bucket
|
||||||
|
ORDER BY time_bucket ASC LIMIT 100
|
||||||
|
LOOP
|
||||||
|
RAISE NOTICE '-> cron_windy_fn checking metrics [%]', metric_rec;
|
||||||
|
-- https://community.windy.com/topic/8168/report-your-weather-station-data-to-windy
|
||||||
|
-- temp from kelvin to celcuis
|
||||||
|
-- winddir from radiant to degres
|
||||||
|
-- rh from ratio to percentage
|
||||||
|
SELECT jsonb_build_object(
|
||||||
|
'dateutc', metric_rec.time_bucket,
|
||||||
|
'station', windy_rec.id,
|
||||||
|
'name', windy_rec.name,
|
||||||
|
'lat', metric_rec.lat,
|
||||||
|
'lon', metric_rec.lng,
|
||||||
|
'wind', metric_rec.wind,
|
||||||
|
'gust', metric_rec.gust,
|
||||||
|
'pressure', metric_rec.pressure,
|
||||||
|
'winddir', radiantToDegrees(metric_rec.winddir::numeric),
|
||||||
|
'temp', kelvinToCel(metric_rec.temperature::numeric),
|
||||||
|
'rh', valToPercent(metric_rec.rh::numeric)
|
||||||
|
) INTO windy_metric;
|
||||||
|
RAISE NOTICE '-> cron_windy_fn checking windy_metrics [%]', windy_metric;
|
||||||
|
SELECT windy_pws_py_fn(windy_metric, user_settings, app_settings) into windy_pws;
|
||||||
|
RAISE NOTICE '-> cron_windy_fn Windy PWS [%]', ((windy_pws->'header')::JSONB ? 'id');
|
||||||
|
IF NOT((user_settings->'settings')::JSONB ? 'windy') and ((windy_pws->'header')::JSONB ? 'id') then
|
||||||
|
RAISE NOTICE '-> cron_windy_fn new Windy PWS [%]', (windy_pws->'header')::JSONB->>'id';
|
||||||
|
-- Send metrics to Windy
|
||||||
|
PERFORM api.update_user_preferences_fn('{windy}'::TEXT, ((windy_pws->'header')::JSONB->>'id')::TEXT);
|
||||||
|
-- Send notification
|
||||||
|
PERFORM send_notification_fn('windy'::TEXT, user_settings::JSONB);
|
||||||
|
END IF;
|
||||||
|
-- Record last metrics time
|
||||||
|
SELECT metric_rec.time_bucket INTO last_metric;
|
||||||
|
END LOOP;
|
||||||
|
PERFORM api.update_user_preferences_fn('{windy_last_metric}'::TEXT, last_metric::TEXT);
|
||||||
|
END LOOP;
|
||||||
|
END;
|
||||||
|
$$ language plpgsql;
|
||||||
|
-- Description
|
||||||
|
COMMENT ON FUNCTION
|
||||||
|
public.cron_process_windy_fn
|
||||||
|
IS 'init by pg_cron to create (or update) station and uploading observations to Windy Personal Weather Station observations';
|
||||||
|
|
||||||
-- CRON for Vacuum database
|
-- CRON for Vacuum database
|
||||||
CREATE FUNCTION cron_vacuum_fn() RETURNS void AS $$
|
CREATE FUNCTION cron_vacuum_fn() RETURNS void AS $$
|
||||||
-- ERROR: VACUUM cannot be executed from a function
|
-- ERROR: VACUUM cannot be executed from a function
|
||||||
@@ -426,44 +517,305 @@ COMMENT ON FUNCTION
|
|||||||
IS 'init by pg_cron to full vacuum tables on schema api';
|
IS 'init by pg_cron to full vacuum tables on schema api';
|
||||||
|
|
||||||
-- CRON for alerts notification
|
-- CRON for alerts notification
|
||||||
CREATE FUNCTION cron_process_alerts_fn() RETURNS void AS $$
|
CREATE OR REPLACE FUNCTION public.cron_alerts_fn() RETURNS void AS $$
|
||||||
DECLARE
|
DECLARE
|
||||||
alert_rec record;
|
alert_rec record;
|
||||||
|
default_last_metric TIMESTAMPTZ := NOW() - interval '1 day';
|
||||||
last_metric TIMESTAMPTZ;
|
last_metric TIMESTAMPTZ;
|
||||||
metric_rec record;
|
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
|
BEGIN
|
||||||
-- Check for new event notification pending update
|
-- Check for new event notification pending update
|
||||||
RAISE NOTICE 'cron_process_alerts_fn';
|
RAISE NOTICE 'cron_alerts_fn';
|
||||||
FOR alert_rec in
|
FOR alert_rec in
|
||||||
SELECT
|
SELECT
|
||||||
a.user_id,a.email,v.vessel_id
|
a.user_id,a.email,v.vessel_id,
|
||||||
FROM auth.accounts a, auth.vessels v, api.metadata m
|
COALESCE((a.preferences->'alert_last_metric')::TEXT, default_last_metric::TEXT) as last_metric,
|
||||||
WHERE m.vessel_id = v.vessel_id
|
(alert_default || (a.preferences->'alerting')::JSONB) as alerting,
|
||||||
AND a.email = v.owner_email
|
(a.preferences->'alarms')::JSONB as alarms
|
||||||
AND (a.preferences->'alerting'->'enabled')::boolean = True
|
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
|
AND m.active = True
|
||||||
LOOP
|
LOOP
|
||||||
RAISE NOTICE '-> cron_process_alert_rec_fn for [%]', alert_rec;
|
RAISE NOTICE '-> cron_alerts_fn for [%]', alert_rec;
|
||||||
PERFORM set_config('vessel.id', alert_rec.vessel_id, false);
|
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);
|
--RAISE WARNING 'public.cron_process_alert_rec_fn() scheduler vessel.id %, user.id', current_setting('vessel.id', false), current_setting('user.id', false);
|
||||||
-- Get time from the last metrics entry
|
-- Gather user settings
|
||||||
SELECT m.time INTO last_metric FROM api.metrics m WHERE vessel_id = alert_rec.vessel_id ORDER BY m.time DESC LIMIT 1;
|
user_settings := get_user_settings_from_vesselid_fn(alert_rec.vessel_id::TEXT);
|
||||||
-- Get all metrics from the last 10 minutes
|
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
|
FOR metric_rec in
|
||||||
SELECT *
|
SELECT time_bucket('5 minutes', m.time) AS time_bucket,
|
||||||
|
avg((m.metrics->'environment.inside.temperature')::numeric) AS intemp,
|
||||||
|
avg((m.metrics->'environment.outside.temperature')::numeric) AS outtemp,
|
||||||
|
avg((m.metrics->'environment.water.temperature')::numeric) AS wattemp,
|
||||||
|
avg((m.metrics->'environment.depth.belowTransducer')::numeric) AS watdepth,
|
||||||
|
avg((m.metrics->'environment.outside.pressure')::numeric) AS pressure,
|
||||||
|
avg((m.metrics->'environment.wind.speedTrue')::numeric) AS wind,
|
||||||
|
avg((m.metrics->'electrical.batteries.House.voltage')::numeric) AS voltage,
|
||||||
|
avg((m.metrics->'electrical.batteries.House.capacity.stateOfCharge')::numeric) AS charge
|
||||||
FROM api.metrics m
|
FROM api.metrics m
|
||||||
WHERE vessel_id = alert_rec.vessel_id
|
WHERE vessel_id = alert_rec.vessel_id
|
||||||
AND time >= last_metric - INTERVAL '10 MINUTES'
|
AND m.time >= alert_rec.last_metric::TIMESTAMPTZ
|
||||||
ORDER BY m.time DESC LIMIT 100
|
GROUP BY time_bucket
|
||||||
|
ORDER BY time_bucket ASC LIMIT 100
|
||||||
LOOP
|
LOOP
|
||||||
RAISE NOTICE '-> cron_process_alert_rec_fn checking metrics [%]', metric_rec;
|
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 kelvinToCel(metric_rec.intemp) < (alert_rec.alerting->'low_indoor_temperature_threshold')::numeric then
|
||||||
|
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_indoor_temperature_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_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) ||'"}'::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 kelvinToCel(metric_rec.outtemp) < (alert_rec.alerting->'low_outdoor_temperature_threshold')::numeric then
|
||||||
|
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_outdoor_temperature_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_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) ||'"}'::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 kelvinToCel(metric_rec.wattemp) < (alert_rec.alerting->'low_water_temperature_threshold')::numeric then
|
||||||
|
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_water_temperature_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_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) ||'"}'::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 < (alert_rec.alerting->'low_water_depth_threshold')::numeric then
|
||||||
|
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_water_depth_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_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:'|| metric_rec.watdepth ||'"}'::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 < (alert_rec.alerting->'high_pressure_drop_threshold')::numeric then
|
||||||
|
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'high_pressure_drop_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->'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:'|| metric_rec.pressure ||'"}'::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 > (alert_rec.alerting->'high_wind_speed_threshold')::numeric then
|
||||||
|
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'high_wind_speed_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->'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:'|| metric_rec.wind ||'"}'::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 < (alert_rec.alerting->'low_battery_voltage_threshold')::numeric then
|
||||||
|
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_battery_voltage_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 = 'lacroix.francois@gmail.com';
|
||||||
|
-- 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:'|| metric_rec.voltage ||'"}'::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*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:'|| (metric_rec.charge*100) ||'"}'::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;
|
END LOOP;
|
||||||
|
PERFORM api.update_user_preferences_fn('{alert_last_metric}'::TEXT, last_metric::TEXT);
|
||||||
END LOOP;
|
END LOOP;
|
||||||
END;
|
END;
|
||||||
$$ language plpgsql;
|
$$ language plpgsql;
|
||||||
-- Description
|
-- Description
|
||||||
COMMENT ON FUNCTION
|
COMMENT ON FUNCTION
|
||||||
public.cron_process_alerts_fn
|
public.cron_alerts_fn
|
||||||
IS 'init by pg_cron to check for alerts';
|
IS 'init by pg_cron to check for alerts';
|
||||||
|
|
||||||
-- CRON for no vessel notification
|
-- CRON for no vessel notification
|
||||||
@@ -625,7 +977,7 @@ COMMENT ON FUNCTION
|
|||||||
-- Need to be in the postgres database.
|
-- Need to be in the postgres database.
|
||||||
\c postgres
|
\c postgres
|
||||||
-- CRON for clean up job details logs
|
-- CRON for clean up job details logs
|
||||||
CREATE FUNCTION job_run_details_cleanup_fn() RETURNS void AS $$
|
CREATE FUNCTION public.job_run_details_cleanup_fn() RETURNS void AS $$
|
||||||
DECLARE
|
DECLARE
|
||||||
BEGIN
|
BEGIN
|
||||||
-- Remove job run log older than 3 months
|
-- Remove job run log older than 3 months
|
||||||
|
@@ -105,27 +105,27 @@ INSERT INTO public.email_templates VALUES
|
|||||||
E'You requested a password recovery. Check your email!\n'),
|
E'You requested a password recovery. Check your email!\n'),
|
||||||
('telegram_otp',
|
('telegram_otp',
|
||||||
'Telegram bot',
|
'Telegram bot',
|
||||||
E'Hello,\nTo connect your account to a @postgsail_bot. Please type this verification code __OTP_CODE__ back to the bot.\nThe code is valid 15 minutes.\nThe PostgSail Team',
|
E'Hello,\nTo connect your account to a @postgsail_bot. Please type this verification code __OTP_CODE__ back to the bot.\nThe code is valid 15 minutes.\nFrancois',
|
||||||
'Telegram bot',
|
'Telegram bot',
|
||||||
E'Hello,\nTo connect your account to a @postgsail_bot. Check your email!\n'),
|
E'Hello,\nTo connect your account to a @postgsail_bot. Check your email!\n'),
|
||||||
('telegram_valid',
|
('telegram_valid',
|
||||||
'Telegram bot',
|
'Telegram bot',
|
||||||
E'Hello __RECIPIENT__,\nCongratulations! You have just connect your account to your vessel, @postgsail_bot.\n\nThe PostgSail Team',
|
E'Hello __RECIPIENT__,\nCongratulations! You have just connect your account to your vessel, @postgsail_bot.\nFrancois',
|
||||||
'Telegram bot!',
|
'Telegram bot!',
|
||||||
E'Congratulations!\nYou have just connect your account to your vessel, @postgsail_bot.\n'),
|
E'Congratulations!\nYou have just connect your account to your vessel, @postgsail_bot.\n'),
|
||||||
('no_vessel',
|
('no_vessel',
|
||||||
'PostgSail add your boat',
|
'PostgSail add your boat',
|
||||||
E'Hello __RECIPIENT__,\nYou created an account on PostgSail but you have not added your boat yet.\nIf you need any assistance, I would be happy to help. It is free and an open-source.\nThe PostgSail Team',
|
E'Hello __RECIPIENT__,\nYou created an account on PostgSail but you have not added your boat yet.\nIf you need any assistance, I would be happy to help. It is free and an open-source.\nFrancois',
|
||||||
'PostgSail next step',
|
'PostgSail next step',
|
||||||
E'Hello,\nYou should create your vessel. Check your email!\n'),
|
E'Hello,\nYou should create your vessel. Check your email!\n'),
|
||||||
('no_metadata',
|
('no_metadata',
|
||||||
'PostgSail connect your boat',
|
'PostgSail connect your boat',
|
||||||
E'Hello __RECIPIENT__,\nYou created an account on PostgSail but you have not connected your boat yet.\nIf you need any assistance, I would be happy to help. It is free and an open-source.\nThe PostgSail Team',
|
E'Hello __RECIPIENT__,\nYou created an account on PostgSail but you have not connected your boat yet.\nIf you need any assistance, I would be happy to help. It is free and an open-source.\nFrancois',
|
||||||
'PostgSail next step',
|
'PostgSail next step',
|
||||||
E'Hello,\nYou should connect your vessel. Check your email!\n'),
|
E'Hello,\nYou should connect your vessel. Check your email!\n'),
|
||||||
('no_activity',
|
('no_activity',
|
||||||
'PostgSail boat inactivity',
|
'PostgSail boat inactivity',
|
||||||
E'Hello __RECIPIENT__,\nWe don\'t see any activity on your account, do you need any assistance?\nIf you need any assistance, I would be happy to help. It is free and an open-source.\nThe PostgSail Team.',
|
E'Hello __RECIPIENT__,\nWe don\'t see any activity on your account, do you need any assistance?\nIf you need any assistance, I would be happy to help. It is free and an open-source.\nFrancois.',
|
||||||
'PostgSail inactivity!',
|
'PostgSail inactivity!',
|
||||||
E'We detected inactivity. Check your email!\n'),
|
E'We detected inactivity. Check your email!\n'),
|
||||||
('deactivated',
|
('deactivated',
|
||||||
@@ -137,7 +137,17 @@ INSERT INTO public.email_templates VALUES
|
|||||||
'PostgSail Grafana integration',
|
'PostgSail Grafana integration',
|
||||||
E'Hello __RECIPIENT__,\nCongratulations! You unlocked Grafana dashboard.\nSee more details at https://app.openplotter.cloud\nHappy sailing!\nFrancois',
|
E'Hello __RECIPIENT__,\nCongratulations! You unlocked Grafana dashboard.\nSee more details at https://app.openplotter.cloud\nHappy sailing!\nFrancois',
|
||||||
'PostgSail Grafana!',
|
'PostgSail Grafana!',
|
||||||
E'Congratulations!\nYou unlocked Grafana dashboard.\nSee more details at https://app.openplotter.cloud\n');
|
E'Congratulations!\nYou unlocked Grafana dashboard.\nSee more details at https://app.openplotter.cloud\n'),
|
||||||
|
('windy',
|
||||||
|
'PostgSail Windy Weather station',
|
||||||
|
E'Hello __RECIPIENT__,\nCongratulations! Your boat is now a Windy Weather station.\nSee more details at __APP_URL__/windy\nHappy sailing!\nFrancois',
|
||||||
|
'PostgSail Windy!',
|
||||||
|
E'Congratulations!\nYour boat is now a Windy Weather station.\nSee more details at __APP_URL__/windy\n'),
|
||||||
|
('alert',
|
||||||
|
'PostgSail Alert',
|
||||||
|
E'Hello __RECIPIENT__,\nWe detected an alert __ALERT__.\nSee more details at __APP_URL__\nStay safe.\nFrancois',
|
||||||
|
'PostgSail Alert!',
|
||||||
|
E'We detected an alert __ALERT__.\n');
|
||||||
|
|
||||||
---------------------------------------------------------------------------
|
---------------------------------------------------------------------------
|
||||||
-- Queue handling
|
-- Queue handling
|
||||||
|
@@ -829,7 +829,8 @@ BEGIN
|
|||||||
OR name LIKE 'app.url'
|
OR name LIKE 'app.url'
|
||||||
OR name LIKE 'app.telegram%'
|
OR name LIKE 'app.telegram%'
|
||||||
OR name LIKE 'app.grafana_admin_uri'
|
OR name LIKE 'app.grafana_admin_uri'
|
||||||
OR name LIKE 'app.keycloak_uri';
|
OR name LIKE 'app.keycloak_uri'
|
||||||
|
OR name LIKE 'app.windy_apikey';
|
||||||
END;
|
END;
|
||||||
$get_app_settings$
|
$get_app_settings$
|
||||||
LANGUAGE plpgsql;
|
LANGUAGE plpgsql;
|
||||||
@@ -942,9 +943,7 @@ AS $get_user_settings_from_vesselid$
|
|||||||
'boat' , v.name,
|
'boat' , v.name,
|
||||||
'recipient', a.first,
|
'recipient', a.first,
|
||||||
'email', v.owner_email,
|
'email', v.owner_email,
|
||||||
'settings', a.preferences,
|
'settings', a.preferences
|
||||||
'pushover_key', a.preferences->'pushover_key'
|
|
||||||
--'badges', a.preferences->'badges'
|
|
||||||
) INTO user_settings
|
) INTO user_settings
|
||||||
FROM auth.accounts a, auth.vessels v, api.metadata m
|
FROM auth.accounts a, auth.vessels v, api.metadata m
|
||||||
WHERE m.vessel_id = v.vessel_id
|
WHERE m.vessel_id = v.vessel_id
|
||||||
|
@@ -196,3 +196,45 @@ language plpgsql volatile;
|
|||||||
COMMENT ON FUNCTION
|
COMMENT ON FUNCTION
|
||||||
public.uuid_generate_v7
|
public.uuid_generate_v7
|
||||||
IS 'Generate UUID v7, Based off IETF draft, https://datatracker.ietf.org/doc/draft-peabody-dispatch-new-uuid-format/';
|
IS 'Generate UUID v7, Based off IETF draft, https://datatracker.ietf.org/doc/draft-peabody-dispatch-new-uuid-format/';
|
||||||
|
|
||||||
|
---------------------------------------------------------------------------
|
||||||
|
-- Conversion helpers
|
||||||
|
--
|
||||||
|
CREATE OR REPLACE FUNCTION public.kelvinToCel(IN temperature NUMERIC)
|
||||||
|
RETURNS NUMERIC
|
||||||
|
AS $$
|
||||||
|
BEGIN
|
||||||
|
RETURN ROUND((((temperature)::numeric - 273.15) * 10) / 10);
|
||||||
|
END
|
||||||
|
$$
|
||||||
|
LANGUAGE plpgsql IMMUTABLE;
|
||||||
|
-- Description
|
||||||
|
COMMENT ON FUNCTION
|
||||||
|
public.kelvinToCel
|
||||||
|
IS 'convert kelvin To Celsius';
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION public.radiantToDegrees(IN angle NUMERIC)
|
||||||
|
RETURNS NUMERIC
|
||||||
|
AS $$
|
||||||
|
BEGIN
|
||||||
|
RETURN ROUND((((angle)::numeric * 57.2958) * 10) / 10);
|
||||||
|
END
|
||||||
|
$$
|
||||||
|
LANGUAGE plpgsql IMMUTABLE;
|
||||||
|
-- Description
|
||||||
|
COMMENT ON FUNCTION
|
||||||
|
public.radiantToDegrees
|
||||||
|
IS 'convert radiant To Degrees';
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION public.valToPercent(IN val NUMERIC)
|
||||||
|
RETURNS NUMERIC
|
||||||
|
AS $$
|
||||||
|
BEGIN
|
||||||
|
RETURN (val * 100);
|
||||||
|
END
|
||||||
|
$$
|
||||||
|
LANGUAGE plpgsql IMMUTABLE;
|
||||||
|
-- Description
|
||||||
|
COMMENT ON FUNCTION
|
||||||
|
public.valToPercent
|
||||||
|
IS 'convert radiant To Degrees';
|
@@ -142,6 +142,8 @@ AS $send_email_py$
|
|||||||
email_content = email_content.replace('__OTP_CODE__', _user['otp_code'])
|
email_content = email_content.replace('__OTP_CODE__', _user['otp_code'])
|
||||||
if 'reset_qs' in _user and _user['reset_qs']:
|
if 'reset_qs' in _user and _user['reset_qs']:
|
||||||
email_content = email_content.replace('__RESET_QS__', _user['reset_qs'])
|
email_content = email_content.replace('__RESET_QS__', _user['reset_qs'])
|
||||||
|
if 'alert' in _user and _user['alert']:
|
||||||
|
email_content = email_content.replace('__ALERT__', _user['alert'])
|
||||||
|
|
||||||
if 'app.url' in app and app['app.url']:
|
if 'app.url' in app and app['app.url']:
|
||||||
email_content = email_content.replace('__APP_URL__', app['app.url'])
|
email_content = email_content.replace('__APP_URL__', app['app.url'])
|
||||||
@@ -231,6 +233,8 @@ AS $send_pushover_py$
|
|||||||
pushover_message = pushover_message.replace('__BOAT__', _user['boat'])
|
pushover_message = pushover_message.replace('__BOAT__', _user['boat'])
|
||||||
if 'badge' in _user and _user['badge']:
|
if 'badge' in _user and _user['badge']:
|
||||||
pushover_message = pushover_message.replace('__BADGE_NAME__', _user['badge'])
|
pushover_message = pushover_message.replace('__BADGE_NAME__', _user['badge'])
|
||||||
|
if 'alert' in _user and _user['alert']:
|
||||||
|
pushover_message = pushover_message.replace('__ALERT__', _user['alert'])
|
||||||
|
|
||||||
if 'app.url' in app and app['app.url']:
|
if 'app.url' in app and app['app.url']:
|
||||||
pushover_message = pushover_message.replace('__APP_URL__', app['app.url'])
|
pushover_message = pushover_message.replace('__APP_URL__', app['app.url'])
|
||||||
@@ -307,6 +311,8 @@ AS $send_telegram_py$
|
|||||||
telegram_message = telegram_message.replace('__BOAT__', _user['boat'])
|
telegram_message = telegram_message.replace('__BOAT__', _user['boat'])
|
||||||
if 'badge' in _user and _user['badge']:
|
if 'badge' in _user and _user['badge']:
|
||||||
telegram_message = telegram_message.replace('__BADGE_NAME__', _user['badge'])
|
telegram_message = telegram_message.replace('__BADGE_NAME__', _user['badge'])
|
||||||
|
if 'alert' in _user and _user['alert']:
|
||||||
|
telegram_message = telegram_message.replace('__ALERT__', _user['alert'])
|
||||||
|
|
||||||
if 'app.url' in app and app['app.url']:
|
if 'app.url' in app and app['app.url']:
|
||||||
telegram_message = telegram_message.replace('__APP_URL__', app['app.url'])
|
telegram_message = telegram_message.replace('__APP_URL__', app['app.url'])
|
||||||
@@ -515,16 +521,22 @@ AS $grafana_py$
|
|||||||
plpy.error('Error no grafana_admin_uri defined, check app settings')
|
plpy.error('Error no grafana_admin_uri defined, check app settings')
|
||||||
return None
|
return None
|
||||||
|
|
||||||
|
b_name = None
|
||||||
|
if not _v_name:
|
||||||
|
b_name = _v_id
|
||||||
|
else:
|
||||||
|
b_name = _v_name
|
||||||
|
|
||||||
# add vessel org
|
# add vessel org
|
||||||
headers = {'User-Agent': 'PostgSail', 'From': 'xbgmsharp@gmail.com',
|
headers = {'User-Agent': 'PostgSail', 'From': 'xbgmsharp@gmail.com',
|
||||||
'Accept': 'application/json', 'Content-Type': 'application/json'}
|
'Accept': 'application/json', 'Content-Type': 'application/json'}
|
||||||
path = 'api/orgs'
|
path = 'api/orgs'
|
||||||
url = f'{grafana_uri}/{path}'.format(grafana_uri,path)
|
url = f'{grafana_uri}/{path}'.format(grafana_uri,path)
|
||||||
data_dict = {'name':_v_name}
|
data_dict = {'name':b_name}
|
||||||
data = json.dumps(data_dict)
|
data = json.dumps(data_dict)
|
||||||
r = requests.post(url, data=data, headers=headers)
|
r = requests.post(url, data=data, headers=headers)
|
||||||
#print(r.text)
|
#print(r.text)
|
||||||
plpy.notice(r.json())
|
#plpy.notice(r.json())
|
||||||
if r.status_code == 200 and "orgId" in r.json():
|
if r.status_code == 200 and "orgId" in r.json():
|
||||||
org_id = r.json()['orgId']
|
org_id = r.json()['orgId']
|
||||||
else:
|
else:
|
||||||
@@ -538,7 +550,7 @@ AS $grafana_py$
|
|||||||
data = json.dumps(data_dict)
|
data = json.dumps(data_dict)
|
||||||
r = requests.post(url, data=data, headers=headers)
|
r = requests.post(url, data=data, headers=headers)
|
||||||
#print(r.text)
|
#print(r.text)
|
||||||
plpy.notice(r.json())
|
#plpy.notice(r.json())
|
||||||
if r.status_code == 200 and "id" in r.json():
|
if r.status_code == 200 and "id" in r.json():
|
||||||
user_id = r.json()['id']
|
user_id = r.json()['id']
|
||||||
else:
|
else:
|
||||||
@@ -550,7 +562,7 @@ AS $grafana_py$
|
|||||||
url = f'{grafana_uri}/{path}'.format(grafana_uri,path)
|
url = f'{grafana_uri}/{path}'.format(grafana_uri,path)
|
||||||
r = requests.get(url, headers=headers)
|
r = requests.get(url, headers=headers)
|
||||||
#print(r.text)
|
#print(r.text)
|
||||||
plpy.notice(r.json())
|
#plpy.notice(r.json())
|
||||||
data_source = r.json()
|
data_source = r.json()
|
||||||
data_source['id'] = 0
|
data_source['id'] = 0
|
||||||
data_source['orgId'] = org_id
|
data_source['orgId'] = org_id
|
||||||
@@ -567,7 +579,7 @@ AS $grafana_py$
|
|||||||
data = json.dumps(data_source)
|
data = json.dumps(data_source)
|
||||||
headers['X-Grafana-Org-Id'] = str(org_id)
|
headers['X-Grafana-Org-Id'] = str(org_id)
|
||||||
r = requests.post(url, data=data, headers=headers)
|
r = requests.post(url, data=data, headers=headers)
|
||||||
plpy.notice(r.json())
|
#plpy.notice(r.json())
|
||||||
del headers['X-Grafana-Org-Id']
|
del headers['X-Grafana-Org-Id']
|
||||||
if r.status_code != 200 and "id" not in r.json():
|
if r.status_code != 200 and "id" not in r.json():
|
||||||
plpy.error('Error grafana add data_source to vessel org')
|
plpy.error('Error grafana add data_source to vessel org')
|
||||||
@@ -581,7 +593,7 @@ AS $grafana_py$
|
|||||||
if 'X-Grafana-Org-Id' in headers:
|
if 'X-Grafana-Org-Id' in headers:
|
||||||
del headers['X-Grafana-Org-Id']
|
del headers['X-Grafana-Org-Id']
|
||||||
r = requests.get(url, headers=headers)
|
r = requests.get(url, headers=headers)
|
||||||
plpy.notice(r.json())
|
#plpy.notice(r.json())
|
||||||
if r.status_code != 200 and "id" not in r.json():
|
if r.status_code != 200 and "id" not in r.json():
|
||||||
plpy.error('Error grafana read dashboard template')
|
plpy.error('Error grafana read dashboard template')
|
||||||
return
|
return
|
||||||
@@ -598,7 +610,7 @@ AS $grafana_py$
|
|||||||
new_data = data.replace('PCC52D03280B7034C', data_source['uid'])
|
new_data = data.replace('PCC52D03280B7034C', data_source['uid'])
|
||||||
headers['X-Grafana-Org-Id'] = str(org_id)
|
headers['X-Grafana-Org-Id'] = str(org_id)
|
||||||
r = requests.post(url, data=new_data, headers=headers)
|
r = requests.post(url, data=new_data, headers=headers)
|
||||||
plpy.notice(r.json())
|
#plpy.notice(r.json())
|
||||||
if r.status_code != 200 and "id" not in r.json():
|
if r.status_code != 200 and "id" not in r.json():
|
||||||
plpy.error('Error grafana add dashboard to vessel org')
|
plpy.error('Error grafana add dashboard to vessel org')
|
||||||
return
|
return
|
||||||
@@ -612,7 +624,7 @@ AS $grafana_py$
|
|||||||
data = json.dumps(home_dashboard)
|
data = json.dumps(home_dashboard)
|
||||||
headers['X-Grafana-Org-Id'] = str(org_id)
|
headers['X-Grafana-Org-Id'] = str(org_id)
|
||||||
r = requests.patch(url, data=data, headers=headers)
|
r = requests.patch(url, data=data, headers=headers)
|
||||||
plpy.notice(r.json())
|
#plpy.notice(r.json())
|
||||||
if r.status_code != 200:
|
if r.status_code != 200:
|
||||||
plpy.error('Error grafana update org preferences')
|
plpy.error('Error grafana update org preferences')
|
||||||
return
|
return
|
||||||
@@ -682,14 +694,14 @@ $keycloak_py$ strict TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
|||||||
-- Description
|
-- Description
|
||||||
COMMENT ON FUNCTION
|
COMMENT ON FUNCTION
|
||||||
public.keycloak_py_fn
|
public.keycloak_py_fn
|
||||||
IS 'Return set oauth user attribute into keycloak using plpython3u';
|
IS 'Set oauth user attribute into keycloak using plpython3u';
|
||||||
|
|
||||||
DROP FUNCTION IF EXISTS keycloak_auth_py_fn;
|
DROP FUNCTION IF EXISTS keycloak_auth_py_fn;
|
||||||
CREATE OR REPLACE FUNCTION keycloak_auth_py_fn(IN _v_id TEXT,
|
CREATE OR REPLACE FUNCTION keycloak_auth_py_fn(IN _v_id TEXT,
|
||||||
IN _user JSONB, IN app JSONB) RETURNS JSONB
|
IN _user JSONB, IN app JSONB) RETURNS JSONB
|
||||||
AS $keycloak_auth_py$
|
AS $keycloak_auth_py$
|
||||||
"""
|
"""
|
||||||
Addkeycloak user
|
Add keycloak user
|
||||||
"""
|
"""
|
||||||
import requests
|
import requests
|
||||||
import json
|
import json
|
||||||
@@ -726,7 +738,7 @@ AS $keycloak_auth_py$
|
|||||||
#plpy.notice(url)
|
#plpy.notice(url)
|
||||||
if r.status_code == 200 and 'access_token' in r.json():
|
if r.status_code == 200 and 'access_token' in r.json():
|
||||||
response = r.json()
|
response = r.json()
|
||||||
plpy.notice(response)
|
#plpy.notice(response)
|
||||||
_headers['Authorization'] = 'Bearer '+ response['access_token']
|
_headers['Authorization'] = 'Bearer '+ response['access_token']
|
||||||
_headers['Content-Type'] = 'application/json'
|
_headers['Content-Type'] = 'application/json'
|
||||||
url = f'{_.scheme}://{host}/admin/realms/postgsail/users'.format(_.scheme, host)
|
url = f'{_.scheme}://{host}/admin/realms/postgsail/users'.format(_.scheme, host)
|
||||||
@@ -738,7 +750,7 @@ AS $keycloak_auth_py$
|
|||||||
"emailVerified": True,
|
"emailVerified": True,
|
||||||
"requiredActions":["UPDATE_PROFILE", "UPDATE_PASSWORD"]
|
"requiredActions":["UPDATE_PROFILE", "UPDATE_PASSWORD"]
|
||||||
}
|
}
|
||||||
plpy.notice(_payload)
|
#plpy.notice(_payload)
|
||||||
data = json.dumps(_payload)
|
data = json.dumps(_payload)
|
||||||
r = requests.post(url, headers=_headers, data=data, timeout=(5, 60))
|
r = requests.post(url, headers=_headers, data=data, timeout=(5, 60))
|
||||||
if r.status_code != 201:
|
if r.status_code != 201:
|
||||||
@@ -750,7 +762,7 @@ AS $keycloak_auth_py$
|
|||||||
plpy.notice('Created user : {u} {t}, {l}'.format(u=_payload['email'], t=r.text, l=r.headers['location']))
|
plpy.notice('Created user : {u} {t}, {l}'.format(u=_payload['email'], t=r.text, l=r.headers['location']))
|
||||||
user_url = "{user_url}/execute-actions-email".format(user_url=r.headers['location'])
|
user_url = "{user_url}/execute-actions-email".format(user_url=r.headers['location'])
|
||||||
_payload = ["UPDATE_PASSWORD"]
|
_payload = ["UPDATE_PASSWORD"]
|
||||||
plpy.notice(_payload)
|
#plpy.notice(_payload)
|
||||||
data = json.dumps(_payload)
|
data = json.dumps(_payload)
|
||||||
r = requests.put(user_url, headers=_headers, data=data, timeout=(5, 60))
|
r = requests.put(user_url, headers=_headers, data=data, timeout=(5, 60))
|
||||||
if r.status_code != 204:
|
if r.status_code != 204:
|
||||||
@@ -765,4 +777,83 @@ $keycloak_auth_py$ strict TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
|||||||
-- Description
|
-- Description
|
||||||
COMMENT ON FUNCTION
|
COMMENT ON FUNCTION
|
||||||
public.keycloak_auth_py_fn
|
public.keycloak_auth_py_fn
|
||||||
IS 'Return set oauth user attribute into keycloak using plpython3u';
|
IS 'Create an oauth user into keycloak using plpython3u';
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION windy_pws_py_fn(IN metric JSONB,
|
||||||
|
IN _user JSONB, IN app JSONB) RETURNS JSONB
|
||||||
|
AS $windy_pws_py$
|
||||||
|
"""
|
||||||
|
Send environment data from boat instruments to Windy as a Personal Weather Station (PWS)
|
||||||
|
https://community.windy.com/topic/8168/report-your-weather-station-data-to-windy
|
||||||
|
"""
|
||||||
|
import requests
|
||||||
|
import json
|
||||||
|
import decimal
|
||||||
|
|
||||||
|
if not 'app.windy_apikey' in app and not app['app.windy_apikey']:
|
||||||
|
plpy.error('Error no windy_apikey defined, check app settings')
|
||||||
|
return none
|
||||||
|
if not 'station' in metric and not metric['station']:
|
||||||
|
plpy.error('Error no metrics defined')
|
||||||
|
return none
|
||||||
|
if not 'temp' in metric and not metric['temp']:
|
||||||
|
plpy.error('Error no metrics defined')
|
||||||
|
return none
|
||||||
|
if not _user:
|
||||||
|
plpy.error('Error no user defined, check user settings')
|
||||||
|
return none
|
||||||
|
|
||||||
|
_headers = {'User-Agent': 'PostgSail', 'From': 'xbgmsharp@gmail.com', 'Content-Type': 'application/json'}
|
||||||
|
_payload = {
|
||||||
|
'stations': [
|
||||||
|
{ 'station': int(decimal.Decimal(metric['station'])),
|
||||||
|
'name': metric['name'],
|
||||||
|
'shareOption': 'Open',
|
||||||
|
'type': 'SignalK PostgSail Plugin',
|
||||||
|
'provider': 'PostgSail',
|
||||||
|
'url': 'https://iot.openplotter.cloud/{name}/monitoring'.format(name=metric['name']),
|
||||||
|
'lat': float(decimal.Decimal(metric['lat'])),
|
||||||
|
'lon': float(decimal.Decimal(metric['lon'])),
|
||||||
|
'elevation': 1 }
|
||||||
|
],
|
||||||
|
'observations': [
|
||||||
|
{ 'station': int(decimal.Decimal(metric['station'])),
|
||||||
|
'temp': float(decimal.Decimal(metric['temp'])),
|
||||||
|
'wind': round(float(decimal.Decimal(metric['wind']))),
|
||||||
|
'gust': round(float(decimal.Decimal(metric['wind']))),
|
||||||
|
'winddir': int(decimal.Decimal(metric['winddir'])),
|
||||||
|
'pressure': int(decimal.Decimal(metric['pressure'])),
|
||||||
|
'rh': float(decimal.Decimal(metric['rh'])) }
|
||||||
|
]}
|
||||||
|
#print(_payload)
|
||||||
|
#plpy.notice(_payload)
|
||||||
|
data = json.dumps(_payload)
|
||||||
|
api_url = 'https://stations.windy.com/pws/update/{api_key}'.format(api_key=app['app.windy_apikey'])
|
||||||
|
r = requests.post(api_url, data=data, headers=_headers, timeout=(5, 60))
|
||||||
|
#print(r.text)
|
||||||
|
#plpy.notice(api_url)
|
||||||
|
if r.status_code == 200:
|
||||||
|
#print('Data sent successfully!')
|
||||||
|
plpy.notice('Data sent successfully to Windy!')
|
||||||
|
#plpy.notice(api_url)
|
||||||
|
if not 'windy' in _user['settings']:
|
||||||
|
api_url = 'https://stations.windy.com/pws/station/{api_key}/{station}'.format(api_key=app['app.windy_apikey'], station=metric['station'])
|
||||||
|
#print(r.text)
|
||||||
|
#plpy.notice(api_url)
|
||||||
|
r = requests.get(api_url, timeout=(5, 60))
|
||||||
|
if r.status_code == 200:
|
||||||
|
#print('Windy Personal Weather Station created successfully in Windy Stations!')
|
||||||
|
plpy.notice('Windy Personal Weather Station created successfully in Windy Stations!')
|
||||||
|
return r.json()
|
||||||
|
else:
|
||||||
|
plpy.error(f'Failed to gather PWS details. Status code: {r.status_code}')
|
||||||
|
else:
|
||||||
|
plpy.error(f'Failed to send data. Status code: {r.status_code}')
|
||||||
|
#print(f'Failed to send data. Status code: {r.status_code}')
|
||||||
|
#print(r.text)
|
||||||
|
return {}
|
||||||
|
$windy_pws_py$ strict TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
||||||
|
-- Description
|
||||||
|
COMMENT ON FUNCTION
|
||||||
|
public.windy_pws_py_fn
|
||||||
|
IS 'Forward vessel data to Windy as a Personal Weather Station using plpython3u';
|
||||||
|
@@ -49,6 +49,9 @@ SELECT cron.schedule('cron_monitor_online', '*/10 * * * *', 'select public.cron_
|
|||||||
-- Create a every 5 minute job cron_process_grafana_fn
|
-- Create a every 5 minute job cron_process_grafana_fn
|
||||||
SELECT cron.schedule('cron_grafana', '*/5 * * * *', 'select public.cron_process_grafana_fn()');
|
SELECT cron.schedule('cron_grafana', '*/5 * * * *', 'select public.cron_process_grafana_fn()');
|
||||||
|
|
||||||
|
-- Create a every 5 minute job cron_process_windy_fn
|
||||||
|
SELECT cron.schedule('cron_windy', '*/5 * * * *', 'select public.cron_windy_fn()');
|
||||||
|
|
||||||
-- Notification
|
-- Notification
|
||||||
-- Create a every 1 minute job cron_process_new_notification_queue_fn, new_account, new_vessel, _new_account_otp
|
-- Create a every 1 minute job cron_process_new_notification_queue_fn, new_account, new_vessel, _new_account_otp
|
||||||
SELECT cron.schedule('cron_new_notification', '*/1 * * * *', 'select public.cron_process_new_notification_fn()');
|
SELECT cron.schedule('cron_new_notification', '*/1 * * * *', 'select public.cron_process_new_notification_fn()');
|
||||||
@@ -68,23 +71,23 @@ SELECT cron.schedule('cron_reindex_auth', '1 23 1 * *', 'REINDEX TABLE CONCURREN
|
|||||||
-- Any other maintenance require?
|
-- Any other maintenance require?
|
||||||
|
|
||||||
-- OTP
|
-- OTP
|
||||||
-- Create a every 15 minute job cron_process_prune_otp_fn
|
-- Create a every 15 minute job cron_prune_otp_fn
|
||||||
SELECT cron.schedule('cron_prune_otp', '*/15 * * * *', 'select public.cron_process_prune_otp_fn()');
|
SELECT cron.schedule('cron_prune_otp', '*/15 * * * *', 'select public.cron_prune_otp_fn()');
|
||||||
|
|
||||||
-- Alerts
|
-- Alerts
|
||||||
-- Create a every 11 minute job cron_process_alerts_fn
|
-- Create a every 11 minute job cron_alerts_fn
|
||||||
--SELECT cron.schedule('cron_alerts', '*/11 * * * *', 'select public.cron_process_alerts_fn()');
|
SELECT cron.schedule('cron_alerts', '*/11 * * * *', 'select public.cron_alerts_fn()');
|
||||||
|
|
||||||
-- Notifications/Reminders of no vessel & no metadata & no activity
|
-- Notifications/Reminders of no vessel & no metadata & no activity
|
||||||
-- At 08:05 on Sunday.
|
-- At 08:05 on Sunday.
|
||||||
-- At 08:05 on every 4th day-of-month if it's on Sunday.
|
-- At 08:05 on every 4th day-of-month if it's on Sunday.
|
||||||
SELECT cron.schedule('cron_no_vessel', '5 8 */4 * 0', 'select public.cron_process_no_vessel_fn()');
|
SELECT cron.schedule('cron_no_vessel', '5 8 */4 * 0', 'select public.cron_no_vessel_fn()');
|
||||||
SELECT cron.schedule('cron_no_metadata', '5 8 */4 * 0', 'select public.cron_process_no_metadata_fn()');
|
SELECT cron.schedule('cron_no_metadata', '5 8 */4 * 0', 'select public.cron_no_metadata_fn()');
|
||||||
SELECT cron.schedule('cron_no_activity', '5 8 */4 * 0', 'select public.cron_process_no_activity_fn()');
|
SELECT cron.schedule('cron_no_activity', '5 8 */4 * 0', 'select public.cron_no_activity_fn()');
|
||||||
|
|
||||||
-- Cron job settings
|
-- Cron job settings
|
||||||
UPDATE cron.job SET database = 'signalk';
|
UPDATE cron.job SET database = 'signalk';
|
||||||
UPDATE cron.job SET username = 'username'; -- TODO update to scheduler, pending process_queue update
|
UPDATE cron.job SET username = current_user; -- TODO update to scheduler, pending process_queue update
|
||||||
--UPDATE cron.job SET username = 'username' where jobname = 'cron_vacuum'; -- TODO Update to superuser for vacuum permissions
|
--UPDATE cron.job SET username = 'username' where jobname = 'cron_vacuum'; -- TODO Update to superuser for vacuum permissions
|
||||||
UPDATE cron.job SET nodename = '/var/run/postgresql/'; -- VS default localhost ??
|
UPDATE cron.job SET nodename = '/var/run/postgresql/'; -- VS default localhost ??
|
||||||
UPDATE cron.job SET database = 'postgres' WHERE jobname = 'job_run_details_cleanup';
|
UPDATE cron.job SET database = 'postgres' WHERE jobname = 'job_run_details_cleanup';
|
||||||
|
457
initdb/99_migrations_202401.sql
Normal file
457
initdb/99_migrations_202401.sql
Normal file
@@ -0,0 +1,457 @@
|
|||||||
|
---------------------------------------------------------------------------
|
||||||
|
-- TODO
|
||||||
|
--
|
||||||
|
----------------------------------------
|
||||||
|
----- TODO --------------
|
||||||
|
----------------------------------------
|
||||||
|
|
||||||
|
-- List current database
|
||||||
|
select current_database();
|
||||||
|
|
||||||
|
-- connect to the DB
|
||||||
|
\c signalk
|
||||||
|
|
||||||
|
\echo 'Force timezone, just in case'
|
||||||
|
set timezone to 'UTC';
|
||||||
|
|
||||||
|
COMMENT ON FUNCTION
|
||||||
|
public.cron_process_new_moorage_fn
|
||||||
|
IS 'Deprecated, init by pg_cron to check for new moorage pending update, if so perform process_moorage_queue_fn';
|
||||||
|
|
||||||
|
DROP FUNCTION IF EXISTS reverse_geoip_py_fn;
|
||||||
|
CREATE OR REPLACE FUNCTION reverse_geoip_py_fn(IN _ip TEXT) RETURNS JSONB
|
||||||
|
AS $reverse_geoip_py$
|
||||||
|
"""
|
||||||
|
Return ipapi.co ip details
|
||||||
|
"""
|
||||||
|
import requests
|
||||||
|
import json
|
||||||
|
|
||||||
|
# requests
|
||||||
|
url = f'https://ipapi.co/{_ip}/json/'
|
||||||
|
r = requests.get(url)
|
||||||
|
#print(r.text)
|
||||||
|
#plpy.notice('IP [{}] [{}]'.format(_ip, r.status_code))
|
||||||
|
if r.status_code == 200:
|
||||||
|
#plpy.notice('Got [{}] [{}]'.format(r.text, r.status_code))
|
||||||
|
return r.json()
|
||||||
|
else:
|
||||||
|
plpy.error('Failed to get ip details')
|
||||||
|
return {}
|
||||||
|
$reverse_geoip_py$ IMMUTABLE strict TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
||||||
|
-- Description
|
||||||
|
COMMENT ON FUNCTION
|
||||||
|
public.reverse_geoip_py_fn
|
||||||
|
IS 'Retrieve reverse geo IP location via ipapi.co using plpython3u';
|
||||||
|
|
||||||
|
DROP FUNCTION IF EXISTS overpass_py_fn;
|
||||||
|
CREATE OR REPLACE FUNCTION overpass_py_fn(IN lon NUMERIC, IN lat NUMERIC,
|
||||||
|
OUT geo JSONB) RETURNS JSONB
|
||||||
|
AS $overpass_py$
|
||||||
|
"""
|
||||||
|
Return https://overpass-turbo.eu seamark details within 400m
|
||||||
|
https://overpass-turbo.eu/s/1EaG
|
||||||
|
https://wiki.openstreetmap.org/wiki/Key:seamark:type
|
||||||
|
"""
|
||||||
|
import requests
|
||||||
|
import json
|
||||||
|
import urllib.parse
|
||||||
|
|
||||||
|
headers = {'User-Agent': 'PostgSail', 'From': 'xbgmsharp@gmail.com'}
|
||||||
|
payload = """
|
||||||
|
[out:json][timeout:20];
|
||||||
|
is_in({0},{1})->.result_areas;
|
||||||
|
(
|
||||||
|
area.result_areas["seamark:type"~"(mooring|harbour)"][~"^seamark:.*:category$"~"."];
|
||||||
|
area.result_areas["leisure"="marina"][~"name"~"."];
|
||||||
|
);
|
||||||
|
out tags;
|
||||||
|
nwr(around:400.0,{0},{1})->.all;
|
||||||
|
(
|
||||||
|
nwr.all["seamark:type"~"(mooring|harbour)"][~"^seamark:.*:category$"~"."];
|
||||||
|
nwr.all["seamark:type"~"(anchorage|anchor_berth|berth)"];
|
||||||
|
nwr.all["leisure"="marina"];
|
||||||
|
nwr.all["natural"~"(bay|beach)"];
|
||||||
|
);
|
||||||
|
out tags;
|
||||||
|
""".format(lat, lon)
|
||||||
|
data = urllib.parse.quote(payload, safe="");
|
||||||
|
url = f'https://overpass-api.de/api/interpreter?data={data}'.format(data)
|
||||||
|
r = requests.get(url, headers)
|
||||||
|
#print(r.text)
|
||||||
|
#plpy.notice(url)
|
||||||
|
plpy.notice('overpass-api coord lon[{}] lat[{}] [{}]'.format(lon, lat, r.status_code))
|
||||||
|
if r.status_code == 200 and "elements" in r.json():
|
||||||
|
r_dict = r.json()
|
||||||
|
plpy.notice('overpass-api Got [{}]'.format(r_dict["elements"]))
|
||||||
|
if r_dict["elements"]:
|
||||||
|
if "tags" in r_dict["elements"][0] and r_dict["elements"][0]["tags"]:
|
||||||
|
return r_dict["elements"][0]["tags"]; # return the first element
|
||||||
|
return {}
|
||||||
|
else:
|
||||||
|
plpy.notice('overpass-api Failed to get overpass-api details')
|
||||||
|
return {}
|
||||||
|
$overpass_py$ IMMUTABLE strict TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
||||||
|
-- Description
|
||||||
|
COMMENT ON FUNCTION
|
||||||
|
public.overpass_py_fn
|
||||||
|
IS 'Return https://overpass-turbo.eu seamark details within 400m using plpython3u';
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION get_app_settings_fn(OUT app_settings jsonb)
|
||||||
|
RETURNS jsonb
|
||||||
|
AS $get_app_settings$
|
||||||
|
DECLARE
|
||||||
|
BEGIN
|
||||||
|
SELECT
|
||||||
|
jsonb_object_agg(name, value) INTO app_settings
|
||||||
|
FROM
|
||||||
|
public.app_settings
|
||||||
|
WHERE
|
||||||
|
name LIKE 'app.email%'
|
||||||
|
OR name LIKE 'app.pushover%'
|
||||||
|
OR name LIKE 'app.url'
|
||||||
|
OR name LIKE 'app.telegram%'
|
||||||
|
OR name LIKE 'app.grafana_admin_uri'
|
||||||
|
OR name LIKE 'app.keycloak_uri';
|
||||||
|
END;
|
||||||
|
$get_app_settings$
|
||||||
|
LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION keycloak_auth_py_fn(IN _v_id TEXT,
|
||||||
|
IN _user JSONB, IN app JSONB) RETURNS JSONB
|
||||||
|
AS $keycloak_auth_py$
|
||||||
|
"""
|
||||||
|
Addkeycloak user
|
||||||
|
"""
|
||||||
|
import requests
|
||||||
|
import json
|
||||||
|
import urllib.parse
|
||||||
|
|
||||||
|
safe_uri = host = user = pwd = None
|
||||||
|
if 'app.keycloak_uri' in app and app['app.keycloak_uri']:
|
||||||
|
#safe_uri = urllib.parse.quote(app['app.keycloak_uri'], safe=':/?&=')
|
||||||
|
_ = urllib.parse.urlparse(app['app.keycloak_uri'])
|
||||||
|
host = _.netloc.split('@')[-1]
|
||||||
|
user = _.netloc.split(':')[0]
|
||||||
|
pwd = _.netloc.split(':')[1].split('@')[0]
|
||||||
|
else:
|
||||||
|
plpy.error('Error no keycloak_uri defined, check app settings')
|
||||||
|
return none
|
||||||
|
|
||||||
|
if not host or not user or not pwd:
|
||||||
|
plpy.error('Error parsing keycloak_uri, check app settings')
|
||||||
|
return None
|
||||||
|
|
||||||
|
if not 'email' in _user and _user['email']:
|
||||||
|
plpy.error('Error parsing user email, check user settings')
|
||||||
|
return none
|
||||||
|
|
||||||
|
if not _v_id:
|
||||||
|
plpy.error('Error parsing vessel_id')
|
||||||
|
return none
|
||||||
|
|
||||||
|
_headers = {'User-Agent': 'PostgSail', 'From': 'xbgmsharp@gmail.com'}
|
||||||
|
_payload = {'client_id':'admin-cli','grant_type':'password','username':user,'password':pwd}
|
||||||
|
url = f'{_.scheme}://{host}/realms/master/protocol/openid-connect/token'.format(_.scheme, host)
|
||||||
|
r = requests.post(url, headers=_headers, data=_payload, timeout=(5, 60))
|
||||||
|
#print(r.text)
|
||||||
|
#plpy.notice(url)
|
||||||
|
if r.status_code == 200 and 'access_token' in r.json():
|
||||||
|
response = r.json()
|
||||||
|
plpy.notice(response)
|
||||||
|
_headers['Authorization'] = 'Bearer '+ response['access_token']
|
||||||
|
_headers['Content-Type'] = 'application/json'
|
||||||
|
url = f'{_.scheme}://{host}/admin/realms/postgsail/users'.format(_.scheme, host)
|
||||||
|
_payload = {
|
||||||
|
"enabled": "true",
|
||||||
|
"email": _user['email'],
|
||||||
|
"firstName": _user['recipient'],
|
||||||
|
"attributes": {"vessel_id": _v_id},
|
||||||
|
"emailVerified": True,
|
||||||
|
"requiredActions":["UPDATE_PROFILE", "UPDATE_PASSWORD"]
|
||||||
|
}
|
||||||
|
plpy.notice(_payload)
|
||||||
|
data = json.dumps(_payload)
|
||||||
|
r = requests.post(url, headers=_headers, data=data, timeout=(5, 60))
|
||||||
|
if r.status_code != 201:
|
||||||
|
#print("Error creating user: {status}".format(status=r.status_code))
|
||||||
|
plpy.error(f'Error creating user: {user} {status}'.format(user=_payload['email'], status=r.status_code))
|
||||||
|
return None
|
||||||
|
else:
|
||||||
|
#print("Created user : {u}]".format(u=_payload['email']))
|
||||||
|
plpy.notice('Created user : {u} {t}, {l}'.format(u=_payload['email'], t=r.text, l=r.headers['location']))
|
||||||
|
user_url = "{user_url}/execute-actions-email".format(user_url=r.headers['location'])
|
||||||
|
_payload = ["UPDATE_PASSWORD"]
|
||||||
|
plpy.notice(_payload)
|
||||||
|
data = json.dumps(_payload)
|
||||||
|
r = requests.put(user_url, headers=_headers, data=data, timeout=(5, 60))
|
||||||
|
if r.status_code != 204:
|
||||||
|
plpy.error('Error execute-actions-email: {u} {s}'.format(u=_user['email'], s=r.status_code))
|
||||||
|
else:
|
||||||
|
plpy.notice('execute-actions-email: {u} {s}'.format(u=_user['email'], s=r.status_code))
|
||||||
|
return None
|
||||||
|
else:
|
||||||
|
plpy.error(f'Error getting admin access_token: {status}'.format(status=r.status_code))
|
||||||
|
return None
|
||||||
|
$keycloak_auth_py$ strict TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
||||||
|
-- Description
|
||||||
|
COMMENT ON FUNCTION
|
||||||
|
public.keycloak_auth_py_fn
|
||||||
|
IS 'Return set oauth user attribute into keycloak using plpython3u';
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION keycloak_py_fn(IN user_id TEXT, IN vessel_id TEXT,
|
||||||
|
IN app JSONB) RETURNS JSONB
|
||||||
|
AS $keycloak_py$
|
||||||
|
"""
|
||||||
|
Add vessel_id user attribute to keycloak user {user_id}
|
||||||
|
"""
|
||||||
|
import requests
|
||||||
|
import json
|
||||||
|
import urllib.parse
|
||||||
|
|
||||||
|
safe_uri = host = user = pwd = None
|
||||||
|
if 'app.keycloak_uri' in app and app['app.keycloak_uri']:
|
||||||
|
#safe_uri = urllib.parse.quote(app['app.keycloak_uri'], safe=':/?&=')
|
||||||
|
_ = urllib.parse.urlparse(app['app.keycloak_uri'])
|
||||||
|
host = _.netloc.split('@')[-1]
|
||||||
|
user = _.netloc.split(':')[0]
|
||||||
|
pwd = _.netloc.split(':')[1].split('@')[0]
|
||||||
|
else:
|
||||||
|
plpy.error('Error no keycloak_uri defined, check app settings')
|
||||||
|
return None
|
||||||
|
|
||||||
|
if not host or not user or not pwd:
|
||||||
|
plpy.error('Error parsing keycloak_uri, check app settings')
|
||||||
|
return None
|
||||||
|
|
||||||
|
_headers = {'User-Agent': 'PostgSail', 'From': 'xbgmsharp@gmail.com'}
|
||||||
|
_payload = {'client_id':'admin-cli','grant_type':'password','username':user,'password':pwd}
|
||||||
|
url = f'{_.scheme}://{host}/realms/master/protocol/openid-connect/token'.format(_.scheme, host)
|
||||||
|
r = requests.post(url, headers=_headers, data=_payload, timeout=(5, 60))
|
||||||
|
#print(r.text)
|
||||||
|
#plpy.notice(url)
|
||||||
|
if r.status_code == 200 and 'access_token' in r.json():
|
||||||
|
response = r.json()
|
||||||
|
plpy.notice(response)
|
||||||
|
_headers['Authorization'] = 'Bearer '+ response['access_token']
|
||||||
|
_headers['Content-Type'] = 'application/json'
|
||||||
|
_payload = { 'attributes': {'vessel_id': vessel_id} }
|
||||||
|
url = f'{keycloak_uri}/admin/realms/postgsail/users/{user_id}'.format(keycloak_uri,user_id)
|
||||||
|
#plpy.notice(url)
|
||||||
|
#plpy.notice(_payload)
|
||||||
|
data = json.dumps(_payload)
|
||||||
|
r = requests.put(url, headers=_headers, data=data, timeout=(5, 60))
|
||||||
|
if r.status_code != 204:
|
||||||
|
plpy.notice("Error updating user: {status} [{text}]".format(
|
||||||
|
status=r.status_code, text=r.text))
|
||||||
|
return None
|
||||||
|
else:
|
||||||
|
plpy.notice("Updated user : {user} [{text}]".format(user=user_id, text=r.text))
|
||||||
|
else:
|
||||||
|
plpy.notice(f'Error getting admin access_token: {status} [{text}]'.format(
|
||||||
|
status=r.status_code, text=r.text))
|
||||||
|
return None
|
||||||
|
$keycloak_py$ strict TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
||||||
|
|
||||||
|
UPDATE public.email_templates
|
||||||
|
SET pushover_message='Congratulations!
|
||||||
|
You unlocked Grafana dashboard.
|
||||||
|
See more details at https://app.openplotter.cloud
|
||||||
|
',email_content='Hello __RECIPIENT__,
|
||||||
|
Congratulations! You unlocked Grafana dashboard.
|
||||||
|
See more details at https://app.openplotter.cloud
|
||||||
|
Happy sailing!
|
||||||
|
Francois'
|
||||||
|
WHERE "name"='grafana';
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION public.cron_process_grafana_fn()
|
||||||
|
RETURNS void
|
||||||
|
LANGUAGE plpgsql
|
||||||
|
AS $function$
|
||||||
|
DECLARE
|
||||||
|
process_rec record;
|
||||||
|
data_rec record;
|
||||||
|
app_settings jsonb;
|
||||||
|
user_settings jsonb;
|
||||||
|
BEGIN
|
||||||
|
-- We run grafana provisioning only after the first received vessel metadata
|
||||||
|
-- Check for new vessel metadata pending grafana provisioning
|
||||||
|
RAISE NOTICE 'cron_process_grafana_fn';
|
||||||
|
FOR process_rec in
|
||||||
|
SELECT * from process_queue
|
||||||
|
where channel = 'grafana' and processed is null
|
||||||
|
order by stored asc
|
||||||
|
LOOP
|
||||||
|
RAISE NOTICE '-> cron_process_grafana_fn [%]', process_rec.payload;
|
||||||
|
-- Gather url from app settings
|
||||||
|
app_settings := get_app_settings_fn();
|
||||||
|
-- Get vessel details base on metadata id
|
||||||
|
SELECT * INTO data_rec
|
||||||
|
FROM api.metadata m, auth.vessels v
|
||||||
|
WHERE m.id = process_rec.payload::INTEGER
|
||||||
|
AND m.vessel_id = v.vessel_id;
|
||||||
|
-- as we got data from the vessel we can do the grafana provisioning.
|
||||||
|
PERFORM grafana_py_fn(data_rec.name, data_rec.vessel_id, data_rec.owner_email, app_settings);
|
||||||
|
-- Gather user settings
|
||||||
|
user_settings := get_user_settings_from_vesselid_fn(data_rec.vessel_id::TEXT);
|
||||||
|
RAISE DEBUG '-> DEBUG cron_process_grafana_fn get_user_settings_from_vesselid_fn [%]', user_settings;
|
||||||
|
-- add user in keycloak
|
||||||
|
PERFORM keycloak_auth_py_fn(data_rec.vessel_id, user_settings, app_settings);
|
||||||
|
-- Send notification
|
||||||
|
PERFORM send_notification_fn('grafana'::TEXT, user_settings::JSONB);
|
||||||
|
-- update process_queue entry as processed
|
||||||
|
UPDATE process_queue
|
||||||
|
SET
|
||||||
|
processed = NOW()
|
||||||
|
WHERE id = process_rec.id;
|
||||||
|
RAISE NOTICE '-> cron_process_grafana_fn updated process_queue table [%]', process_rec.id;
|
||||||
|
END LOOP;
|
||||||
|
END;
|
||||||
|
$function$
|
||||||
|
;
|
||||||
|
COMMENT ON FUNCTION public.cron_process_grafana_fn() IS 'init by pg_cron to check for new vessel pending grafana provisioning, if so perform grafana_py_fn';
|
||||||
|
|
||||||
|
-- DROP FUNCTION public.grafana_py_fn(text, text, text, jsonb);
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION public.grafana_py_fn(_v_name text, _v_id text, _u_email text, app jsonb)
|
||||||
|
RETURNS void
|
||||||
|
TRANSFORM FOR TYPE jsonb
|
||||||
|
LANGUAGE plpython3u
|
||||||
|
AS $function$
|
||||||
|
"""
|
||||||
|
https://grafana.com/docs/grafana/latest/developers/http_api/
|
||||||
|
Create organization base on vessel name
|
||||||
|
Create user base on user email
|
||||||
|
Add user to organization
|
||||||
|
Add data_source to organization
|
||||||
|
Add dashboard to organization
|
||||||
|
Update organization preferences
|
||||||
|
"""
|
||||||
|
import requests
|
||||||
|
import json
|
||||||
|
import re
|
||||||
|
|
||||||
|
grafana_uri = None
|
||||||
|
if 'app.grafana_admin_uri' in app and app['app.grafana_admin_uri']:
|
||||||
|
grafana_uri = app['app.grafana_admin_uri']
|
||||||
|
else:
|
||||||
|
plpy.error('Error no grafana_admin_uri defined, check app settings')
|
||||||
|
return None
|
||||||
|
|
||||||
|
b_name = None
|
||||||
|
if not _v_name:
|
||||||
|
b_name = _v_id
|
||||||
|
else:
|
||||||
|
b_name = _v_name
|
||||||
|
|
||||||
|
# add vessel org
|
||||||
|
headers = {'User-Agent': 'PostgSail', 'From': 'xbgmsharp@gmail.com',
|
||||||
|
'Accept': 'application/json', 'Content-Type': 'application/json'}
|
||||||
|
path = 'api/orgs'
|
||||||
|
url = f'{grafana_uri}/{path}'.format(grafana_uri,path)
|
||||||
|
data_dict = {'name':b_name}
|
||||||
|
data = json.dumps(data_dict)
|
||||||
|
r = requests.post(url, data=data, headers=headers)
|
||||||
|
#print(r.text)
|
||||||
|
plpy.notice(r.json())
|
||||||
|
if r.status_code == 200 and "orgId" in r.json():
|
||||||
|
org_id = r.json()['orgId']
|
||||||
|
else:
|
||||||
|
plpy.error('Error grafana add vessel org %', r.json())
|
||||||
|
return none
|
||||||
|
|
||||||
|
# add user to vessel org
|
||||||
|
path = 'api/admin/users'
|
||||||
|
url = f'{grafana_uri}/{path}'.format(grafana_uri,path)
|
||||||
|
data_dict = {'orgId':org_id, 'email':_u_email, 'password':'asupersecretpassword'}
|
||||||
|
data = json.dumps(data_dict)
|
||||||
|
r = requests.post(url, data=data, headers=headers)
|
||||||
|
#print(r.text)
|
||||||
|
plpy.notice(r.json())
|
||||||
|
if r.status_code == 200 and "id" in r.json():
|
||||||
|
user_id = r.json()['id']
|
||||||
|
else:
|
||||||
|
plpy.error('Error grafana add user to vessel org')
|
||||||
|
return
|
||||||
|
|
||||||
|
# read data_source
|
||||||
|
path = 'api/datasources/1'
|
||||||
|
url = f'{grafana_uri}/{path}'.format(grafana_uri,path)
|
||||||
|
r = requests.get(url, headers=headers)
|
||||||
|
#print(r.text)
|
||||||
|
plpy.notice(r.json())
|
||||||
|
data_source = r.json()
|
||||||
|
data_source['id'] = 0
|
||||||
|
data_source['orgId'] = org_id
|
||||||
|
data_source['uid'] = "ds_" + _v_id
|
||||||
|
data_source['name'] = "ds_" + _v_id
|
||||||
|
data_source['secureJsonData'] = {}
|
||||||
|
data_source['secureJsonData']['password'] = 'mysecretpassword'
|
||||||
|
data_source['readOnly'] = True
|
||||||
|
del data_source['secureJsonFields']
|
||||||
|
|
||||||
|
# add data_source to vessel org
|
||||||
|
path = 'api/datasources'
|
||||||
|
url = f'{grafana_uri}/{path}'.format(grafana_uri,path)
|
||||||
|
data = json.dumps(data_source)
|
||||||
|
headers['X-Grafana-Org-Id'] = str(org_id)
|
||||||
|
r = requests.post(url, data=data, headers=headers)
|
||||||
|
plpy.notice(r.json())
|
||||||
|
del headers['X-Grafana-Org-Id']
|
||||||
|
if r.status_code != 200 and "id" not in r.json():
|
||||||
|
plpy.error('Error grafana add data_source to vessel org')
|
||||||
|
return
|
||||||
|
|
||||||
|
dashboards_tpl = [ 'pgsail_tpl_electrical', 'pgsail_tpl_logbook', 'pgsail_tpl_monitor', 'pgsail_tpl_rpi', 'pgsail_tpl_solar', 'pgsail_tpl_weather', 'pgsail_tpl_home']
|
||||||
|
for dashboard in dashboards_tpl:
|
||||||
|
# read dashboard template by uid
|
||||||
|
path = 'api/dashboards/uid'
|
||||||
|
url = f'{grafana_uri}/{path}/{dashboard}'.format(grafana_uri,path,dashboard)
|
||||||
|
if 'X-Grafana-Org-Id' in headers:
|
||||||
|
del headers['X-Grafana-Org-Id']
|
||||||
|
r = requests.get(url, headers=headers)
|
||||||
|
plpy.notice(r.json())
|
||||||
|
if r.status_code != 200 and "id" not in r.json():
|
||||||
|
plpy.error('Error grafana read dashboard template')
|
||||||
|
return
|
||||||
|
new_dashboard = r.json()
|
||||||
|
del new_dashboard['meta']
|
||||||
|
new_dashboard['dashboard']['version'] = 0
|
||||||
|
new_dashboard['dashboard']['id'] = 0
|
||||||
|
new_uid = re.sub(r'pgsail_tpl_(.*)', r'postgsail_\1', new_dashboard['dashboard']['uid'])
|
||||||
|
new_dashboard['dashboard']['uid'] = f'{new_uid}_{_v_id}'.format(new_uid,_v_id)
|
||||||
|
# add dashboard to vessel org
|
||||||
|
path = 'api/dashboards/db'
|
||||||
|
url = f'{grafana_uri}/{path}'.format(grafana_uri,path)
|
||||||
|
data = json.dumps(new_dashboard)
|
||||||
|
new_data = data.replace('PCC52D03280B7034C', data_source['uid'])
|
||||||
|
headers['X-Grafana-Org-Id'] = str(org_id)
|
||||||
|
r = requests.post(url, data=new_data, headers=headers)
|
||||||
|
plpy.notice(r.json())
|
||||||
|
if r.status_code != 200 and "id" not in r.json():
|
||||||
|
plpy.error('Error grafana add dashboard to vessel org')
|
||||||
|
return
|
||||||
|
|
||||||
|
# Update Org Prefs
|
||||||
|
path = 'api/org/preferences'
|
||||||
|
url = f'{grafana_uri}/{path}'.format(grafana_uri,path)
|
||||||
|
home_dashboard = {}
|
||||||
|
home_dashboard['timezone'] = 'utc'
|
||||||
|
home_dashboard['homeDashboardUID'] = f'postgsail_home_{_v_id}'.format(_v_id)
|
||||||
|
data = json.dumps(home_dashboard)
|
||||||
|
headers['X-Grafana-Org-Id'] = str(org_id)
|
||||||
|
r = requests.patch(url, data=data, headers=headers)
|
||||||
|
plpy.notice(r.json())
|
||||||
|
if r.status_code != 200:
|
||||||
|
plpy.error('Error grafana update org preferences')
|
||||||
|
return
|
||||||
|
|
||||||
|
plpy.notice('Done')
|
||||||
|
$function$
|
||||||
|
;
|
||||||
|
|
||||||
|
COMMENT ON FUNCTION public.grafana_py_fn(text, text, text, jsonb) IS 'Grafana Organization,User,data_source,dashboards provisioning via HTTP API using plpython3u';
|
||||||
|
|
||||||
|
UPDATE public.app_settings
|
||||||
|
SET value='0.6.1'
|
||||||
|
WHERE "name"='app.version';
|
740
initdb/99_migrations_202402.sql
Normal file
740
initdb/99_migrations_202402.sql
Normal file
@@ -0,0 +1,740 @@
|
|||||||
|
---------------------------------------------------------------------------
|
||||||
|
-- TODO
|
||||||
|
--
|
||||||
|
----------------------------------------
|
||||||
|
----- TODO --------------
|
||||||
|
----------------------------------------
|
||||||
|
|
||||||
|
-- List current database
|
||||||
|
select current_database();
|
||||||
|
|
||||||
|
-- connect to the DB
|
||||||
|
\c signalk
|
||||||
|
|
||||||
|
\echo 'Force timezone, just in case'
|
||||||
|
set timezone to 'UTC';
|
||||||
|
|
||||||
|
-- Update email_templates
|
||||||
|
--INSERT INTO public.email_templates ("name",email_subject,email_content,pushover_title,pushover_message)
|
||||||
|
-- VALUES ('windy','PostgSail Windy Weather station',E'Hello __RECIPIENT__,\nCongratulations! Your boat is now a Windy Weather station.\nSee more details at __APP_URL__/windy\nHappy sailing!\nFrancois','PostgSail Windy!',E'Congratulations!\nYour boat is now a Windy Weather station.\nSee more details at __APP_URL__/windy\n');
|
||||||
|
--INSERT INTO public.email_templates ("name",email_subject,email_content,pushover_title,pushover_message)
|
||||||
|
--VALUES ('alert','PostgSail Alert',E'Hello __RECIPIENT__,\nWe detected an alert __ALERT__.\nSee more details at __APP_URL__\nStay safe.\nFrancois','PostgSail Alert!',E'Congratulations!\nWe detected an alert __ALERT__.\n');
|
||||||
|
|
||||||
|
INSERT INTO public.email_templates ("name",email_subject,email_content,pushover_title,pushover_message)
|
||||||
|
VALUES ('windy_error','PostgSail Windy Weather station Error','Hello __RECIPIENT__,\nSorry!We could not convert your boat to a Windy Personal Weather Station.\nWindy Personal Weather Station is now disable.','PostgSail Windy error!','Sorry!\nWe could not convert your boat to a Windy Personal Weather Station.');
|
||||||
|
|
||||||
|
-- Update app_settings
|
||||||
|
CREATE OR REPLACE FUNCTION public.get_app_settings_fn(OUT app_settings jsonb)
|
||||||
|
RETURNS jsonb
|
||||||
|
AS $get_app_settings$
|
||||||
|
DECLARE
|
||||||
|
BEGIN
|
||||||
|
SELECT
|
||||||
|
jsonb_object_agg(name, value) INTO app_settings
|
||||||
|
FROM
|
||||||
|
public.app_settings
|
||||||
|
WHERE
|
||||||
|
name LIKE 'app.email%'
|
||||||
|
OR name LIKE 'app.pushover%'
|
||||||
|
OR name LIKE 'app.url'
|
||||||
|
OR name LIKE 'app.telegram%'
|
||||||
|
OR name LIKE 'app.grafana_admin_uri'
|
||||||
|
OR name LIKE 'app.keycloak_uri'
|
||||||
|
OR name LIKE 'app.windy_apikey';
|
||||||
|
END;
|
||||||
|
$get_app_settings$
|
||||||
|
LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION public.get_user_settings_from_vesselid_fn(
|
||||||
|
IN vesselid TEXT,
|
||||||
|
OUT user_settings JSONB
|
||||||
|
) RETURNS JSONB
|
||||||
|
AS $get_user_settings_from_vesselid$
|
||||||
|
DECLARE
|
||||||
|
BEGIN
|
||||||
|
-- If vessel_id is not NULL
|
||||||
|
IF vesselid IS NULL OR vesselid = '' THEN
|
||||||
|
RAISE WARNING '-> get_user_settings_from_vesselid_fn invalid input %', vesselid;
|
||||||
|
END IF;
|
||||||
|
SELECT
|
||||||
|
json_build_object(
|
||||||
|
'boat' , v.name,
|
||||||
|
'recipient', a.first,
|
||||||
|
'email', v.owner_email,
|
||||||
|
'settings', a.preferences
|
||||||
|
) INTO user_settings
|
||||||
|
FROM auth.accounts a, auth.vessels v, api.metadata m
|
||||||
|
WHERE m.vessel_id = v.vessel_id
|
||||||
|
AND m.vessel_id = vesselid
|
||||||
|
AND a.email = v.owner_email;
|
||||||
|
PERFORM set_config('user.email', user_settings->>'email'::TEXT, false);
|
||||||
|
PERFORM set_config('user.recipient', user_settings->>'recipient'::TEXT, false);
|
||||||
|
END;
|
||||||
|
$get_user_settings_from_vesselid$ LANGUAGE plpgsql;
|
||||||
|
|
||||||
|
-- Create Windy PWS integration
|
||||||
|
CREATE OR REPLACE FUNCTION public.windy_pws_py_fn(IN metric JSONB,
|
||||||
|
IN _user JSONB, IN app JSONB) RETURNS JSONB
|
||||||
|
AS $windy_pws_py$
|
||||||
|
"""
|
||||||
|
Send environment data from boat instruments to Windy as a Personal Weather Station (PWS)
|
||||||
|
https://community.windy.com/topic/8168/report-your-weather-station-data-to-windy
|
||||||
|
"""
|
||||||
|
import requests
|
||||||
|
import json
|
||||||
|
import decimal
|
||||||
|
|
||||||
|
if not 'app.windy_apikey' in app and not app['app.windy_apikey']:
|
||||||
|
plpy.error('Error no windy_apikey defined, check app settings')
|
||||||
|
return none
|
||||||
|
if not 'station' in metric and not metric['station']:
|
||||||
|
plpy.error('Error no metrics defined')
|
||||||
|
return none
|
||||||
|
if not 'temp' in metric and not metric['temp']:
|
||||||
|
plpy.error('Error no metrics defined')
|
||||||
|
return none
|
||||||
|
if not _user:
|
||||||
|
plpy.error('Error no user defined, check user settings')
|
||||||
|
return none
|
||||||
|
|
||||||
|
_headers = {'User-Agent': 'PostgSail', 'From': 'xbgmsharp@gmail.com', 'Content-Type': 'application/json'}
|
||||||
|
_payload = {
|
||||||
|
'stations': [
|
||||||
|
{ 'station': int(decimal.Decimal(metric['station'])),
|
||||||
|
'name': metric['name'],
|
||||||
|
'shareOption': 'Open',
|
||||||
|
'type': 'SignalK PostgSail Plugin',
|
||||||
|
'provider': 'PostgSail',
|
||||||
|
'url': 'https://iot.openplotter.cloud/{name}/monitoring'.format(name=metric['name']),
|
||||||
|
'lat': float(decimal.Decimal(metric['lat'])),
|
||||||
|
'lon': float(decimal.Decimal(metric['lon'])),
|
||||||
|
'elevation': 1 }
|
||||||
|
],
|
||||||
|
'observations': [
|
||||||
|
{ 'station': int(decimal.Decimal(metric['station'])),
|
||||||
|
'temp': float(decimal.Decimal(metric['temp'])),
|
||||||
|
'wind': round(float(decimal.Decimal(metric['wind']))),
|
||||||
|
'gust': round(float(decimal.Decimal(metric['gust']))),
|
||||||
|
'winddir': int(decimal.Decimal(metric['winddir'])),
|
||||||
|
'pressure': int(decimal.Decimal(metric['pressure'])),
|
||||||
|
'rh': float(decimal.Decimal(metric['rh'])) }
|
||||||
|
]}
|
||||||
|
#print(_payload)
|
||||||
|
#plpy.notice(_payload)
|
||||||
|
data = json.dumps(_payload)
|
||||||
|
api_url = 'https://stations.windy.com/pws/update/{api_key}'.format(api_key=app['app.windy_apikey'])
|
||||||
|
r = requests.post(api_url, data=data, headers=_headers, timeout=(5, 60))
|
||||||
|
#print(r.text)
|
||||||
|
#plpy.notice(api_url)
|
||||||
|
if r.status_code == 200:
|
||||||
|
#print('Data sent successfully!')
|
||||||
|
plpy.notice('Data sent successfully to Windy!')
|
||||||
|
#plpy.notice(api_url)
|
||||||
|
if not 'windy' in _user['settings']:
|
||||||
|
api_url = 'https://stations.windy.com/pws/station/{api_key}/{station}'.format(api_key=app['app.windy_apikey'], station=metric['station'])
|
||||||
|
#print(r.text)
|
||||||
|
#plpy.notice(api_url)
|
||||||
|
r = requests.get(api_url, timeout=(5, 60))
|
||||||
|
if r.status_code == 200:
|
||||||
|
#print('Windy Personal Weather Station created successfully in Windy Stations!')
|
||||||
|
plpy.notice('Windy Personal Weather Station created successfully in Windy Stations!')
|
||||||
|
return r.json()
|
||||||
|
else:
|
||||||
|
plpy.error(f'Failed to gather PWS details. Status code: {r.status_code}')
|
||||||
|
else:
|
||||||
|
plpy.error(f'Failed to send data. Status code: {r.status_code}')
|
||||||
|
#print(f'Failed to send data. Status code: {r.status_code}')
|
||||||
|
#print(r.text)
|
||||||
|
return {}
|
||||||
|
$windy_pws_py$ strict TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
||||||
|
-- Description
|
||||||
|
COMMENT ON FUNCTION
|
||||||
|
public.windy_pws_py_fn
|
||||||
|
IS 'Forward vessel data to Windy as a Personal Weather Station using plpython3u';
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION public.cron_windy_fn() RETURNS void AS $$
|
||||||
|
DECLARE
|
||||||
|
windy_rec record;
|
||||||
|
default_last_metric TIMESTAMPTZ := NOW() - interval '1 day';
|
||||||
|
last_metric TIMESTAMPTZ;
|
||||||
|
metric_rec record;
|
||||||
|
windy_metric jsonb;
|
||||||
|
app_settings jsonb;
|
||||||
|
user_settings jsonb;
|
||||||
|
windy_pws jsonb;
|
||||||
|
BEGIN
|
||||||
|
-- Check for new observations pending update
|
||||||
|
RAISE NOTICE 'cron_windy_fn';
|
||||||
|
-- Gather url from app settings
|
||||||
|
app_settings := get_app_settings_fn();
|
||||||
|
-- Find users with Windy active and with an active vessel
|
||||||
|
-- Map account id to Windy Station ID
|
||||||
|
FOR windy_rec in
|
||||||
|
SELECT
|
||||||
|
a.id,a.email,v.vessel_id,v.name,
|
||||||
|
COALESCE((a.preferences->'windy_last_metric')::TEXT, default_last_metric::TEXT) as last_metric
|
||||||
|
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->'public_windy')::boolean = True
|
||||||
|
AND m.active = True
|
||||||
|
LOOP
|
||||||
|
RAISE NOTICE '-> cron_windy_fn for [%]', windy_rec;
|
||||||
|
PERFORM set_config('vessel.id', windy_rec.vessel_id, false);
|
||||||
|
--RAISE WARNING 'public.cron_process_windy_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(windy_rec.vessel_id::TEXT);
|
||||||
|
RAISE NOTICE '-> cron_windy_fn checking user_settings [%]', user_settings;
|
||||||
|
-- Get all metrics from the last windy_last_metric avg by 5 minutes
|
||||||
|
-- TODO json_agg to send all data in once, but issue with py jsonb transformation decimal.
|
||||||
|
FOR metric_rec in
|
||||||
|
SELECT time_bucket('5 minutes', m.time) AS time_bucket,
|
||||||
|
avg((m.metrics->'environment.outside.temperature')::numeric) AS temperature,
|
||||||
|
avg((m.metrics->'environment.outside.pressure')::numeric) AS pressure,
|
||||||
|
avg((m.metrics->'environment.outside.relativeHumidity')::numeric) AS rh,
|
||||||
|
avg((m.metrics->'environment.wind.directionTrue')::numeric) AS winddir,
|
||||||
|
avg((m.metrics->'environment.wind.speedTrue')::numeric) AS wind,
|
||||||
|
max((m.metrics->'environment.wind.speedTrue')::numeric) AS gust,
|
||||||
|
last(latitude, time) AS lat,
|
||||||
|
last(longitude, time) AS lng
|
||||||
|
FROM api.metrics m
|
||||||
|
WHERE vessel_id = windy_rec.vessel_id
|
||||||
|
AND m.time >= windy_rec.last_metric::TIMESTAMPTZ
|
||||||
|
GROUP BY time_bucket
|
||||||
|
ORDER BY time_bucket ASC LIMIT 100
|
||||||
|
LOOP
|
||||||
|
RAISE NOTICE '-> cron_windy_fn checking metrics [%]', metric_rec;
|
||||||
|
-- https://community.windy.com/topic/8168/report-your-weather-station-data-to-windy
|
||||||
|
-- temp from kelvin to celcuis
|
||||||
|
-- winddir from radiant to degres
|
||||||
|
-- rh from ratio to percentage
|
||||||
|
SELECT jsonb_build_object(
|
||||||
|
'dateutc', metric_rec.time_bucket,
|
||||||
|
'station', windy_rec.id,
|
||||||
|
'name', windy_rec.name,
|
||||||
|
'lat', metric_rec.lat,
|
||||||
|
'lon', metric_rec.lng,
|
||||||
|
'wind', metric_rec.wind,
|
||||||
|
'gust', metric_rec.gust,
|
||||||
|
'pressure', metric_rec.pressure,
|
||||||
|
'winddir', radiantToDegrees(metric_rec.winddir::numeric),
|
||||||
|
'temp', kelvinToCel(metric_rec.temperature::numeric),
|
||||||
|
'rh', valToPercent(metric_rec.rh::numeric)
|
||||||
|
) INTO windy_metric;
|
||||||
|
RAISE NOTICE '-> cron_windy_fn checking windy_metrics [%]', windy_metric;
|
||||||
|
SELECT windy_pws_py_fn(windy_metric, user_settings, app_settings) into windy_pws;
|
||||||
|
RAISE NOTICE '-> cron_windy_fn Windy PWS [%]', ((windy_pws->'header')::JSONB ? 'id');
|
||||||
|
IF NOT((user_settings->'settings')::JSONB ? 'windy') and ((windy_pws->'header')::JSONB ? 'id') then
|
||||||
|
RAISE NOTICE '-> cron_windy_fn new Windy PWS [%]', (windy_pws->'header')::JSONB->>'id';
|
||||||
|
-- Send metrics to Windy
|
||||||
|
PERFORM api.update_user_preferences_fn('{windy}'::TEXT, ((windy_pws->'header')::JSONB->>'id')::TEXT);
|
||||||
|
-- Send notification
|
||||||
|
PERFORM send_notification_fn('windy'::TEXT, user_settings::JSONB);
|
||||||
|
END IF;
|
||||||
|
-- Record last metrics time
|
||||||
|
SELECT metric_rec.time_bucket INTO last_metric;
|
||||||
|
END LOOP;
|
||||||
|
PERFORM api.update_user_preferences_fn('{windy_last_metric}'::TEXT, last_metric::TEXT);
|
||||||
|
END LOOP;
|
||||||
|
END;
|
||||||
|
$$ language plpgsql;
|
||||||
|
-- Description
|
||||||
|
COMMENT ON FUNCTION
|
||||||
|
public.cron_windy_fn
|
||||||
|
IS 'init by pg_cron to create (or update) station and uploading observations to Windy Personal Weather Station observations';
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION public.cron_alerts_fn() RETURNS void AS $$
|
||||||
|
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 || (a.preferences->'alerting')::JSONB) as alerting,
|
||||||
|
(a.preferences->'alarms')::JSONB as alarms
|
||||||
|
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((m.metrics->'environment.inside.temperature')::numeric) AS intemp,
|
||||||
|
avg((m.metrics->'environment.outside.temperature')::numeric) AS outtemp,
|
||||||
|
avg((m.metrics->'environment.water.temperature')::numeric) AS wattemp,
|
||||||
|
avg((m.metrics->'environment.depth.belowTransducer')::numeric) AS watdepth,
|
||||||
|
avg((m.metrics->'environment.outside.pressure')::numeric) AS pressure,
|
||||||
|
avg((m.metrics->'environment.wind.speedTrue')::numeric) AS wind,
|
||||||
|
avg((m.metrics->'electrical.batteries.House.voltage')::numeric) AS voltage,
|
||||||
|
avg((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 kelvinToCel(metric_rec.intemp) < (alert_rec.alerting->'low_indoor_temperature_threshold')::numeric then
|
||||||
|
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_indoor_temperature_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_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) ||'"}'::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 kelvinToCel(metric_rec.outtemp) < (alert_rec.alerting->'low_outdoor_temperature_threshold')::numeric then
|
||||||
|
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_outdoor_temperature_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_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) ||'"}'::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 kelvinToCel(metric_rec.wattemp) < (alert_rec.alerting->'low_water_temperature_threshold')::numeric then
|
||||||
|
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_water_temperature_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_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) ||'"}'::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 < (alert_rec.alerting->'low_water_depth_threshold')::numeric then
|
||||||
|
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_water_depth_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_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:'|| metric_rec.watdepth ||'"}'::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 < (alert_rec.alerting->'high_pressure_drop_threshold')::numeric then
|
||||||
|
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'high_pressure_drop_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->'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:'|| metric_rec.pressure ||'"}'::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 > (alert_rec.alerting->'high_wind_speed_threshold')::numeric then
|
||||||
|
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'high_wind_speed_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->'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:'|| metric_rec.wind ||'"}'::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 < (alert_rec.alerting->'low_battery_voltage_threshold')::numeric then
|
||||||
|
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_battery_voltage_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 = 'lacroix.francois@gmail.com';
|
||||||
|
-- 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:'|| metric_rec.voltage ||'"}'::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*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:'|| (metric_rec.charge*100) ||'"}'::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;
|
||||||
|
$$ language plpgsql;
|
||||||
|
-- Description
|
||||||
|
COMMENT ON FUNCTION
|
||||||
|
public.cron_alerts_fn
|
||||||
|
IS 'init by pg_cron to check for alerts';
|
||||||
|
|
||||||
|
-- CRON for no vessel notification
|
||||||
|
CREATE FUNCTION public.cron_no_vessel_fn() RETURNS void AS $no_vessel$
|
||||||
|
DECLARE
|
||||||
|
no_vessel record;
|
||||||
|
user_settings jsonb;
|
||||||
|
BEGIN
|
||||||
|
-- Check for user with no vessel register
|
||||||
|
RAISE NOTICE 'cron_no_vessel_fn';
|
||||||
|
FOR no_vessel in
|
||||||
|
SELECT a.user_id,a.email,a.first
|
||||||
|
FROM auth.accounts a
|
||||||
|
WHERE NOT EXISTS (
|
||||||
|
SELECT *
|
||||||
|
FROM auth.vessels v
|
||||||
|
WHERE v.owner_email = a.email)
|
||||||
|
LOOP
|
||||||
|
RAISE NOTICE '-> cron_no_vessel_rec_fn for [%]', no_vessel;
|
||||||
|
SELECT json_build_object('email', no_vessel.email, 'recipient', no_vessel.first) into user_settings;
|
||||||
|
RAISE NOTICE '-> debug cron_no_vessel_rec_fn [%]', user_settings;
|
||||||
|
-- Send notification
|
||||||
|
PERFORM send_notification_fn('no_vessel'::TEXT, user_settings::JSONB);
|
||||||
|
END LOOP;
|
||||||
|
END;
|
||||||
|
$no_vessel$ language plpgsql;
|
||||||
|
-- Description
|
||||||
|
COMMENT ON FUNCTION
|
||||||
|
public.cron_no_vessel_fn
|
||||||
|
IS 'init by pg_cron, check for user with no vessel register then send notification';
|
||||||
|
|
||||||
|
CREATE FUNCTION public.cron_no_metadata_fn() RETURNS void AS $no_metadata$
|
||||||
|
DECLARE
|
||||||
|
no_metadata_rec record;
|
||||||
|
user_settings jsonb;
|
||||||
|
BEGIN
|
||||||
|
-- Check for vessel register but with no metadata
|
||||||
|
RAISE NOTICE 'cron_no_metadata_fn';
|
||||||
|
FOR no_metadata_rec in
|
||||||
|
SELECT
|
||||||
|
a.user_id,a.email,a.first
|
||||||
|
FROM auth.accounts a, auth.vessels v
|
||||||
|
WHERE NOT EXISTS (
|
||||||
|
SELECT *
|
||||||
|
FROM api.metadata m
|
||||||
|
WHERE v.vessel_id = m.vessel_id) AND v.owner_email = a.email
|
||||||
|
LOOP
|
||||||
|
RAISE NOTICE '-> cron_process_no_metadata_rec_fn for [%]', no_metadata_rec;
|
||||||
|
SELECT json_build_object('email', no_metadata_rec.email, 'recipient', no_metadata_rec.first) into user_settings;
|
||||||
|
RAISE NOTICE '-> debug cron_process_no_metadata_rec_fn [%]', user_settings;
|
||||||
|
-- Send notification
|
||||||
|
PERFORM send_notification_fn('no_metadata'::TEXT, user_settings::JSONB);
|
||||||
|
END LOOP;
|
||||||
|
END;
|
||||||
|
$no_metadata$ language plpgsql;
|
||||||
|
-- Description
|
||||||
|
COMMENT ON FUNCTION
|
||||||
|
public.cron_no_metadata_fn
|
||||||
|
IS 'init by pg_cron, check for vessel with no metadata then send notification';
|
||||||
|
|
||||||
|
CREATE FUNCTION public.cron_no_activity_fn() RETURNS void AS $no_activity$
|
||||||
|
DECLARE
|
||||||
|
no_activity_rec record;
|
||||||
|
user_settings jsonb;
|
||||||
|
BEGIN
|
||||||
|
-- Check for vessel with no activity for more than 230 days
|
||||||
|
RAISE NOTICE 'cron_no_activity_fn';
|
||||||
|
FOR no_activity_rec in
|
||||||
|
SELECT
|
||||||
|
v.owner_email,m.name,m.vessel_id,m.time,a.first
|
||||||
|
FROM auth.accounts a
|
||||||
|
LEFT JOIN auth.vessels v ON v.owner_email = a.email
|
||||||
|
LEFT JOIN api.metadata m ON v.vessel_id = m.vessel_id
|
||||||
|
WHERE m.time < NOW() AT TIME ZONE 'UTC' - INTERVAL '230 DAYS'
|
||||||
|
LOOP
|
||||||
|
RAISE NOTICE '-> cron_process_no_activity_rec_fn for [%]', no_activity_rec;
|
||||||
|
SELECT json_build_object('email', no_activity_rec.owner_email, 'recipient', no_activity_rec.first) into user_settings;
|
||||||
|
RAISE NOTICE '-> debug cron_process_no_activity_rec_fn [%]', user_settings;
|
||||||
|
-- Send notification
|
||||||
|
PERFORM send_notification_fn('no_activity'::TEXT, user_settings::JSONB);
|
||||||
|
END LOOP;
|
||||||
|
END;
|
||||||
|
$no_activity$ language plpgsql;
|
||||||
|
-- Description
|
||||||
|
COMMENT ON FUNCTION
|
||||||
|
public.cron_no_activity_fn
|
||||||
|
IS 'init by pg_cron, check for vessel with no activity for more than 230 days then send notification';
|
||||||
|
|
||||||
|
CREATE FUNCTION public.cron_deactivated_fn() RETURNS void AS $deactivated$
|
||||||
|
DECLARE
|
||||||
|
no_activity_rec record;
|
||||||
|
user_settings jsonb;
|
||||||
|
BEGIN
|
||||||
|
RAISE NOTICE 'cron_deactivated_fn';
|
||||||
|
|
||||||
|
-- List accounts with vessel inactivity for more than 1 YEAR
|
||||||
|
FOR no_activity_rec in
|
||||||
|
SELECT
|
||||||
|
v.owner_email,m.name,m.vessel_id,m.time,a.first
|
||||||
|
FROM auth.accounts a
|
||||||
|
LEFT JOIN auth.vessels v ON v.owner_email = a.email
|
||||||
|
LEFT JOIN api.metadata m ON v.vessel_id = m.vessel_id
|
||||||
|
WHERE m.time < NOW() AT TIME ZONE 'UTC' - INTERVAL '1 YEAR'
|
||||||
|
LOOP
|
||||||
|
RAISE NOTICE '-> cron_process_deactivated_rec_fn for inactivity [%]', no_activity_rec;
|
||||||
|
SELECT json_build_object('email', no_activity_rec.owner_email, 'recipient', no_activity_rec.first) into user_settings;
|
||||||
|
RAISE NOTICE '-> debug cron_process_deactivated_rec_fn inactivity [%]', user_settings;
|
||||||
|
-- Send notification
|
||||||
|
PERFORM send_notification_fn('deactivated'::TEXT, user_settings::JSONB);
|
||||||
|
--PERFORM public.delete_account_fn(no_activity_rec.owner_email::TEXT, no_activity_rec.vessel_id::TEXT);
|
||||||
|
END LOOP;
|
||||||
|
|
||||||
|
-- List accounts with no vessel metadata for more than 1 YEAR
|
||||||
|
FOR no_activity_rec in
|
||||||
|
SELECT
|
||||||
|
a.user_id,a.email,a.first,a.created_at
|
||||||
|
FROM auth.accounts a, auth.vessels v
|
||||||
|
WHERE NOT EXISTS (
|
||||||
|
SELECT *
|
||||||
|
FROM api.metadata m
|
||||||
|
WHERE v.vessel_id = m.vessel_id) AND v.owner_email = a.email
|
||||||
|
AND v.created_at < NOW() AT TIME ZONE 'UTC' - INTERVAL '1 YEAR'
|
||||||
|
LOOP
|
||||||
|
RAISE NOTICE '-> cron_process_deactivated_rec_fn for no metadata [%]', no_activity_rec;
|
||||||
|
SELECT json_build_object('email', no_activity_rec.owner_email, 'recipient', no_activity_rec.first) into user_settings;
|
||||||
|
RAISE NOTICE '-> debug cron_process_deactivated_rec_fn no metadata [%]', user_settings;
|
||||||
|
-- Send notification
|
||||||
|
PERFORM send_notification_fn('deactivated'::TEXT, user_settings::JSONB);
|
||||||
|
--PERFORM public.delete_account_fn(no_activity_rec.owner_email::TEXT, no_activity_rec.vessel_id::TEXT);
|
||||||
|
END LOOP;
|
||||||
|
|
||||||
|
-- List accounts with no vessel created for more than 1 YEAR
|
||||||
|
FOR no_activity_rec in
|
||||||
|
SELECT a.user_id,a.email,a.first,a.created_at
|
||||||
|
FROM auth.accounts a
|
||||||
|
WHERE NOT EXISTS (
|
||||||
|
SELECT *
|
||||||
|
FROM auth.vessels v
|
||||||
|
WHERE v.owner_email = a.email)
|
||||||
|
AND a.created_at < NOW() AT TIME ZONE 'UTC' - INTERVAL '1 YEAR'
|
||||||
|
LOOP
|
||||||
|
RAISE NOTICE '-> cron_process_deactivated_rec_fn for no vessel [%]', no_activity_rec;
|
||||||
|
SELECT json_build_object('email', no_activity_rec.owner_email, 'recipient', no_activity_rec.first) into user_settings;
|
||||||
|
RAISE NOTICE '-> debug cron_process_deactivated_rec_fn no vessel [%]', user_settings;
|
||||||
|
-- Send notification
|
||||||
|
PERFORM send_notification_fn('deactivated'::TEXT, user_settings::JSONB);
|
||||||
|
--PERFORM public.delete_account_fn(no_activity_rec.owner_email::TEXT, no_activity_rec.vessel_id::TEXT);
|
||||||
|
END LOOP;
|
||||||
|
END;
|
||||||
|
$deactivated$ language plpgsql;
|
||||||
|
-- Description
|
||||||
|
COMMENT ON FUNCTION
|
||||||
|
public.cron_deactivated_fn
|
||||||
|
IS 'init by pg_cron, check for vessel with no activity for more than 1 year then send notification and delete data';
|
||||||
|
|
||||||
|
DROP FUNCTION IF EXISTS public.cron_process_prune_otp_fn();
|
||||||
|
DROP FUNCTION IF EXISTS public.cron_process_no_vessel_fn();
|
||||||
|
DROP FUNCTION IF EXISTS public.cron_process_no_metadata_fn();
|
||||||
|
DROP FUNCTION IF EXISTS public.cron_process_no_activity_fn();
|
||||||
|
DROP FUNCTION IF EXISTS public.cron_process_deactivated_fn();
|
||||||
|
DROP FUNCTION IF EXISTS public.cron_process_windy_fn();
|
||||||
|
DROP FUNCTION IF EXISTS public.cron_process_alerts_fn();
|
||||||
|
|
||||||
|
-- Remove deprecated fn
|
||||||
|
DROP FUNCTION public.cron_process_new_account_fn();
|
||||||
|
DROP FUNCTION public.cron_process_new_account_otp_validation_fn();
|
||||||
|
DROP FUNCTION public.cron_process_new_moorage_fn();
|
||||||
|
DROP FUNCTION public.cron_process_new_vessel_fn();
|
||||||
|
|
||||||
|
-- Update version
|
||||||
|
UPDATE public.app_settings
|
||||||
|
SET value='0.7.0'
|
||||||
|
WHERE "name"='app.version';
|
||||||
|
|
||||||
|
-- Create a cron job
|
||||||
|
\c postgres
|
||||||
|
|
||||||
|
UPDATE cron.job
|
||||||
|
SET command='select public.cron_prune_otp_fn()'
|
||||||
|
WHERE jobname = 'cron_prune_otp';
|
||||||
|
UPDATE cron.job
|
||||||
|
SET command='select public.cron_no_vessel_fn()'
|
||||||
|
WHERE jobname = 'cron_no_vessel';
|
||||||
|
UPDATE cron.job
|
||||||
|
SET command='select public.cron_no_metadata_fn()'
|
||||||
|
WHERE jobname = 'cron_no_metadata';
|
||||||
|
UPDATE cron.job
|
||||||
|
SET command='select public.cron_no_activity_fn()'
|
||||||
|
WHERE jobname = 'cron_no_activity';
|
||||||
|
UPDATE cron.job
|
||||||
|
SET command='select public.cron_windy_fn()'
|
||||||
|
WHERE jobname = 'cron_windy';
|
||||||
|
UPDATE cron.job
|
||||||
|
SET command='select public.cron_alerts_fn()'
|
||||||
|
WHERE jobname = 'cron_alerts';
|
||||||
|
|
@@ -1 +1 @@
|
|||||||
0.6.1
|
0.7.0
|
||||||
|
File diff suppressed because one or more lines are too long
@@ -6,10 +6,10 @@
|
|||||||
You are now connected to database "signalk" as user "username".
|
You are now connected to database "signalk" as user "username".
|
||||||
Expanded display is on.
|
Expanded display is on.
|
||||||
-[ RECORD 1 ]--+-------------------------------
|
-[ RECORD 1 ]--+-------------------------------
|
||||||
server_version | 16.1 (Debian 16.1-1.pgdg110+1)
|
server_version | 16.2 (Debian 16.2-1.pgdg110+2)
|
||||||
|
|
||||||
-[ RECORD 1 ]--------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
-[ RECORD 1 ]--------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||||
postgis_full_version | POSTGIS="3.4.1 ca035b9" [EXTENSION] PGSQL="160" GEOS="3.9.0-CAPI-1.16.2" PROJ="7.2.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" LIBXML="2.9.10" LIBJSON="0.15" LIBPROTOBUF="1.3.3" WAGYU="0.5.0 (Internal)"
|
postgis_full_version | POSTGIS="3.4.2 c19ce56" [EXTENSION] PGSQL="160" GEOS="3.9.0-CAPI-1.16.2" PROJ="7.2.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" LIBXML="2.9.10" LIBJSON="0.15" LIBPROTOBUF="1.3.3" WAGYU="0.5.0 (Internal)"
|
||||||
|
|
||||||
-[ RECORD 1 ]--------------------------------------------------------------------------------------
|
-[ RECORD 1 ]--------------------------------------------------------------------------------------
|
||||||
Name | citext
|
Name | citext
|
||||||
@@ -48,12 +48,12 @@ Schema | pg_catalog
|
|||||||
Description | PL/Python3U untrusted procedural language
|
Description | PL/Python3U untrusted procedural language
|
||||||
-[ RECORD 8 ]--------------------------------------------------------------------------------------
|
-[ RECORD 8 ]--------------------------------------------------------------------------------------
|
||||||
Name | postgis
|
Name | postgis
|
||||||
Version | 3.4.1
|
Version | 3.4.2
|
||||||
Schema | public
|
Schema | public
|
||||||
Description | PostGIS geometry and geography spatial types and functions
|
Description | PostGIS geometry and geography spatial types and functions
|
||||||
-[ RECORD 9 ]--------------------------------------------------------------------------------------
|
-[ RECORD 9 ]--------------------------------------------------------------------------------------
|
||||||
Name | timescaledb
|
Name | timescaledb
|
||||||
Version | 2.13.1
|
Version | 2.14.1
|
||||||
Schema | public
|
Schema | public
|
||||||
Description | Enables scalable inserts and complex queries for time-series data (Community Edition)
|
Description | Enables scalable inserts and complex queries for time-series data (Community Edition)
|
||||||
-[ RECORD 10 ]-------------------------------------------------------------------------------------
|
-[ RECORD 10 ]-------------------------------------------------------------------------------------
|
||||||
@@ -106,14 +106,14 @@ laninline | 13543
|
|||||||
lanvalidator | 13544
|
lanvalidator | 13544
|
||||||
lanacl |
|
lanacl |
|
||||||
-[ RECORD 5 ]-+-----------
|
-[ RECORD 5 ]-+-----------
|
||||||
oid | 18297
|
oid | 18175
|
||||||
lanname | plpython3u
|
lanname | plpython3u
|
||||||
lanowner | 10
|
lanowner | 10
|
||||||
lanispl | t
|
lanispl | t
|
||||||
lanpltrusted | t
|
lanpltrusted | t
|
||||||
lanplcallfoid | 18294
|
lanplcallfoid | 18172
|
||||||
laninline | 18295
|
laninline | 18173
|
||||||
lanvalidator | 18296
|
lanvalidator | 18174
|
||||||
lanacl |
|
lanacl |
|
||||||
|
|
||||||
-[ RECORD 1 ]+-----------
|
-[ RECORD 1 ]+-----------
|
||||||
@@ -645,12 +645,12 @@ overpass_py_fn | {"name": "Port de la Ginesta", "type": "multipolygon", "leisure
|
|||||||
overpass_py_fn | {"name": "Norra hamnen", "leisure": "marina"}
|
overpass_py_fn | {"name": "Norra hamnen", "leisure": "marina"}
|
||||||
|
|
||||||
-[ RECORD 1 ]----------------------------------------------------------------------------------------------------------------------------------------------
|
-[ RECORD 1 ]----------------------------------------------------------------------------------------------------------------------------------------------
|
||||||
versions_fn | {"api_version" : "0.6.1", "sys_version" : "PostgreSQL 16.1", "timescaledb" : "2.13.1", "postgis" : "3.4.1", "postgrest" : "PostgREST 12.0.2"}
|
versions_fn | {"api_version" : "0.6.1", "sys_version" : "PostgreSQL 16.2", "timescaledb" : "2.14.1", "postgis" : "3.4.2", "postgrest" : "PostgREST 12.0.2"}
|
||||||
|
|
||||||
-[ RECORD 1 ]-----------------
|
-[ RECORD 1 ]-----------------
|
||||||
api_version | 0.6.1
|
api_version | 0.7.0
|
||||||
sys_version | PostgreSQL 16.1
|
sys_version | PostgreSQL 16.2
|
||||||
timescaledb | 2.13.1
|
timescaledb | 2.14.1
|
||||||
postgis | 3.4.1
|
postgis | 3.4.2
|
||||||
postgrest | PostgREST 12.0.2
|
postgrest | PostgREST 12.0.2
|
||||||
|
|
||||||
|
Reference in New Issue
Block a user