mirror of
https://github.com/xbgmsharp/postgsail.git
synced 2025-09-17 03:07:47 +00:00
Compare commits
19 Commits
Author | SHA1 | Date | |
---|---|---|---|
![]() |
8b8087e56d | ||
![]() |
7b7aae7dfe | ||
![]() |
be27618dac | ||
![]() |
7fb24d8cae | ||
![]() |
07c7628973 | ||
![]() |
e42e52eaf0 | ||
![]() |
97e739ffe9 | ||
![]() |
3fb2534263 | ||
![]() |
9e8009a764 | ||
![]() |
dca77c3293 | ||
![]() |
8af527f574 | ||
![]() |
0f399293eb | ||
![]() |
57dfaf2158 | ||
![]() |
3a2e091744 | ||
![]() |
7c5bd21e80 | ||
![]() |
33af7bec1b | ||
![]() |
023ad56926 | ||
![]() |
91cf679876 | ||
![]() |
1b81900036 |
@@ -10,6 +10,7 @@ PGSAIL_EMAIL_SERVER=localhost
|
||||
#PGSAIL_EMAIL_PASS= Comment if not use
|
||||
#PGSAIL_PUSHOVER_TOKEN= Comment if not use
|
||||
#PGSAIL_PUSHOVER_APP= Comment if not use
|
||||
PGSAIL_APP_URL=http://localhost
|
||||
# POSTGREST ENV Settings
|
||||
PGRST_DB_URI=postgres://authenticator:${PGSAIL_AUTHENTICATOR_PASSWORD}@127.0.0.1:5432/signalk
|
||||
PGRST_JWT_SECRET=_at_least_32__char__long__random
|
||||
|
10
README.md
10
README.md
@@ -1,8 +1,8 @@
|
||||
# PostgSail
|
||||
Effortless cloud based solution for storing and sharing your SignalK data. Allow to effortlessly log your sails and monitor your boat with historical data.
|
||||
Effortless cloud based solution for storing and sharing your SignalK data. Allow you to effortlessly log your sails and monitor your boat with historical data.
|
||||
|
||||
### Context
|
||||
It is all about SQL, object-relational, time-series, spatial database with a bit python.
|
||||
It is all about SQL, object-relational, time-series, spatial databases with a bit of python.
|
||||
|
||||
### Features
|
||||
- Automatically log your voyages without manually starting or stopping a trip.
|
||||
@@ -15,7 +15,7 @@ It is all about SQL, object-relational, time-series, spatial database with a bit
|
||||
- Monitor your boat (position, depth, wind, temperature, battery charge status, etc.) remotely.
|
||||
- History: view trends.
|
||||
- Alert monitoring: get notification on low voltage or low fuel remotely.
|
||||
- Notification via email or PushOver.
|
||||
- Notification via email or PushOver, Telegram
|
||||
|
||||
### Cloud
|
||||
The cloud advantage.
|
||||
@@ -87,7 +87,7 @@ $ curl http://localhost:3000/ -H 'Authorization: Bearer my_token_from_register_v
|
||||
|
||||
#### API main workflow
|
||||
|
||||
Check the [unit test sample](https://github.com/xbgmsharp/PostgSail/blob/main/tests/index.js).
|
||||
Check the [unit test sample](https://github.com/xbgmsharp/postgsail/blob/main/tests/index.js).
|
||||
|
||||
### Docker dependencies
|
||||
|
||||
@@ -115,7 +115,7 @@ Out of the box iot platform using docker with the following software:
|
||||
|
||||
### Support
|
||||
|
||||
To get support, please create new [issue](https://github.com/xbgmsharp/PostgSail/issues).
|
||||
To get support, please create new [issue](https://github.com/xbgmsharp/postgsail/issues).
|
||||
|
||||
There is more likely security flows and bugs.
|
||||
|
||||
|
@@ -469,10 +469,13 @@ COMMENT ON TRIGGER
|
||||
metrics_trigger ON api.metrics
|
||||
IS 'BEFORE INSERT ON api.metrics run function metrics_trigger_fn';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- API helper functions
|
||||
--
|
||||
---------------------------------------------------------------------------
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Functions API schema
|
||||
|
||||
-- Export a log entry to geojson
|
||||
DROP FUNCTION IF EXISTS api.export_logbook_geojson_point_fn;
|
||||
CREATE OR REPLACE FUNCTION api.export_logbook_geojson_point_fn(IN _id INTEGER, OUT geojson JSON) RETURNS JSON AS $export_logbook_geojson_point$
|
||||
@@ -528,7 +531,7 @@ CREATE FUNCTION api.export_logbook_geojson_linestring_fn(IN _id INTEGER) RETURNS
|
||||
geojson json;
|
||||
BEGIN
|
||||
-- If _id is is not NULL and > 0
|
||||
SELECT ST_AsGeoJSON(l.track_geom) INTO geojson
|
||||
SELECT ST_AsGeoJSON(l.*) INTO geojson
|
||||
FROM api.logbook l
|
||||
WHERE l.id = _id;
|
||||
RETURN geojson;
|
||||
@@ -539,6 +542,110 @@ COMMENT ON FUNCTION
|
||||
api.export_logbook_geojson_linestring_fn
|
||||
IS 'Export a log entry to geojson feature linestring';
|
||||
|
||||
-- export_logbook_geojson_fn
|
||||
DROP FUNCTION IF EXISTS api.export_logbook_geojson_fn;
|
||||
CREATE FUNCTION api.export_logbook_geojson_fn(IN _id integer, OUT geojson JSON) RETURNS JSON AS $export_logbook_geojson$
|
||||
DECLARE
|
||||
logbook_rec record;
|
||||
log_geojson jsonb;
|
||||
metrics_geojson jsonb;
|
||||
_map jsonb;
|
||||
BEGIN
|
||||
-- Gather log details
|
||||
-- If _id is is not NULL and > 0
|
||||
SELECT * INTO logbook_rec
|
||||
FROM api.logbook WHERE id = _id;
|
||||
-- GeoJson Feature Logbook linestring
|
||||
SELECT
|
||||
ST_AsGeoJSON(l.*) into log_geojson
|
||||
FROM
|
||||
api.logbook l
|
||||
WHERE l.id = _id;
|
||||
-- GeoJson Feature Metrics point
|
||||
SELECT
|
||||
json_agg(ST_AsGeoJSON(t.*)::json) into metrics_geojson
|
||||
FROM (
|
||||
( SELECT
|
||||
time,
|
||||
courseovergroundtrue,
|
||||
speedoverground,
|
||||
anglespeedapparent,
|
||||
longitude,latitude,
|
||||
st_makepoint(longitude,latitude) AS geo_point
|
||||
FROM api.metrics m
|
||||
WHERE m.latitude IS NOT NULL
|
||||
AND m.longitude IS NOT NULL
|
||||
AND time >= logbook_rec._from_time::TIMESTAMP WITHOUT TIME ZONE
|
||||
AND time <= logbook_rec._to_time::TIMESTAMP WITHOUT TIME ZONE
|
||||
ORDER BY m.time ASC
|
||||
)
|
||||
) AS t;
|
||||
|
||||
-- Merge jsonb
|
||||
select log_geojson::jsonb || metrics_geojson::jsonb into _map;
|
||||
-- output
|
||||
SELECT
|
||||
json_build_object(
|
||||
'type', 'FeatureCollection',
|
||||
'features', _map
|
||||
) into geojson;
|
||||
END;
|
||||
$export_logbook_geojson$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.export_logbook_geojson_fn
|
||||
IS 'Export a log entry to geojson feature linestring and multipoint';
|
||||
|
||||
-- Generate GPX XML file output
|
||||
-- https://opencpn.org/OpenCPN/info/gpxvalidation.html
|
||||
--
|
||||
DROP FUNCTION IF EXISTS api.export_logbook_gpx_fn;
|
||||
CREATE OR REPLACE FUNCTION api.export_logbook_gpx_fn(IN _id INTEGER) RETURNS pg_catalog.xml
|
||||
AS $export_logbook_gpx$
|
||||
DECLARE
|
||||
log_rec record;
|
||||
BEGIN
|
||||
-- Gather log details _from_time and _to_time
|
||||
SELECT * into log_rec
|
||||
FROM
|
||||
api.logbook l
|
||||
WHERE l.id = _id;
|
||||
-- Generate XML
|
||||
RETURN xmlelement(name gpx,
|
||||
xmlattributes( '1.1' as version,
|
||||
'PostgSAIL' as creator,
|
||||
'http://www.topografix.com/GPX/1/1' as xmlns,
|
||||
'http://www.opencpn.org' as "xmlns:opencpn",
|
||||
'http://www.w3.org/2001/XMLSchema-instance' as "xmlns:xsi",
|
||||
'http://www.garmin.com/xmlschemas/GpxExtensions/v3' as "xmlns:gpxx",
|
||||
'http://www.topografix.com/GPX/1/1 http://www.topografix.com/GPX/1/1/gpx.xsd http://www.garmin.com/xmlschemas/GpxExtensions/v3 http://www8.garmin.com/xmlschemas/GpxExtensionsv3.xsd' as "xsi:schemaLocation"),
|
||||
xmlelement(name trk,
|
||||
xmlelement(name name, 'Track Name'),
|
||||
xmlelement(name desc, 'Track Description'),
|
||||
xmlelement(name link, xmlattributes('https://openplotter.cloud/log/{_id}' as href),
|
||||
xmlelement(name text, 'Link name')),
|
||||
xmlelement(name extensions, xmlelement(name "opencpn:guid", uuid_generate_v4()),
|
||||
xmlelement(name "opencpn:viz", '1'),
|
||||
xmlelement(name "opencpn:start", log_rec._from_time),
|
||||
xmlelement(name "opencpn:end", log_rec._to_time)
|
||||
),
|
||||
xmlelement(name trkseg, xmlagg(
|
||||
xmlelement(name trkpt,
|
||||
xmlattributes(latitude as lat, longitude as lon),
|
||||
xmlelement(name time, time)
|
||||
)))))::pg_catalog.xml
|
||||
FROM api.metrics m
|
||||
WHERE m.latitude IS NOT null
|
||||
AND m.longitude IS NOT null
|
||||
AND m.time >= log_rec._from_time::TIMESTAMP WITHOUT TIME ZONE
|
||||
AND m.time <= log_rec._to_time::TIMESTAMP WITHOUT TIME ZONE;
|
||||
END;
|
||||
$export_logbook_gpx$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.export_logbook_gpx_fn
|
||||
IS 'Export a log entry to GPX XML format';
|
||||
|
||||
-- Find all log from and to moorage geopoint within 100m
|
||||
DROP FUNCTION IF EXISTS api.find_log_from_moorage_fn;
|
||||
CREATE FUNCTION api.find_log_from_moorage_fn(IN _id INTEGER) RETURNS void AS $find_log_from_moorage$
|
||||
@@ -603,11 +710,17 @@ COMMENT ON FUNCTION
|
||||
api.find_stay_from_moorage_fn
|
||||
IS 'Find all stay within 100m of moorage geopoint';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- API helper view
|
||||
--
|
||||
---------------------------------------------------------------------------
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Views
|
||||
-- Views are invoked with the privileges of the view owner,
|
||||
-- make the user_role the view’s owner.
|
||||
--
|
||||
---------------------------------------------------------------------------
|
||||
|
||||
CREATE VIEW first_metric AS
|
||||
SELECT *
|
||||
FROM api.metrics
|
||||
@@ -874,107 +987,3 @@ CREATE VIEW api.voltage AS
|
||||
cast(metrics-> 'electrical.batteries.victronDevice.voltage' AS numeric) AS victronDeviceVoltage
|
||||
FROM api.metrics m
|
||||
ORDER BY time DESC LIMIT 1;
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- API helper functions
|
||||
--
|
||||
|
||||
DROP FUNCTION IF EXISTS api.export_logbook_gpx_py_fn;
|
||||
CREATE OR REPLACE FUNCTION api.export_logbook_gpx_py_fn(IN _id INTEGER) RETURNS XML
|
||||
AS $export_logbook_gpx_py$
|
||||
import uuid
|
||||
|
||||
# BEGIN GPX XML format
|
||||
gpx_data = f"""<?xml version="1.0"?>
|
||||
<gpx version="1.1" creator="PostgSAIL" xmlns:xsi="http://www.w3.org/2001/XMLSchema-instance" xmlns="http://www.topografix.com/GPX/1/1" xmlns:gpxx="http://www.garmin.com/xmlschemas/GpxExtensions/v3" xsi:schemaLocation="http://www.topografix.com/GPX/1/1 http://www.topografix.com/GPX/1/1/gpx.xsd" xmlns:opencpn="http://www.opencpn.org">
|
||||
<trk>
|
||||
<link href="https://openplotter.cloud/log/{_id}">
|
||||
<text>openplotter trip log todo</text>
|
||||
</link>
|
||||
<extensions>
|
||||
<opencpn:guid>{uuid.uuid4()}</opencpn:guid>
|
||||
<opencpn:viz>1</opencpn:viz>
|
||||
<opencpn:start>{mytrack[0]['time']}</opencpn:start>
|
||||
<opencpn:end>{mytrack[-1]['time']}</opencpn:end>
|
||||
</extensions>
|
||||
<trkseg>\n""";
|
||||
##print(gpx_data)
|
||||
# LOOP through log entry
|
||||
for entry in mytrack:
|
||||
##print(entry['time'])
|
||||
gpx_data += f""" <trkpt lat="{entry['lat']}" lon="{entry['lng']}">
|
||||
<time>{entry['time']}</time>
|
||||
</trkpt>\n""";
|
||||
|
||||
# END GPX XML format
|
||||
gpx_data += """ </trkseg>
|
||||
</trk>
|
||||
</gpx>""";
|
||||
|
||||
return gpx_data
|
||||
$export_logbook_gpx_py$ LANGUAGE plpython3u;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.export_logbook_gpx_py_fn
|
||||
IS 'TODO, Export a log entry to GPX XML format using plpython3u';
|
||||
|
||||
--DROP FUNCTION IF EXISTS api.export_logbook_csv_fn;
|
||||
--CREATE OR REPLACE FUNCTION api.export_logbook_csv_fn(IN _id INTEGER) RETURNS void
|
||||
--AS $export_logbook_csv$
|
||||
-- TODO
|
||||
--$export_logbook_csv$ language plpgsql;
|
||||
-- Description
|
||||
--COMMENT ON FUNCTION
|
||||
-- api.export_logbook_csv_fn
|
||||
-- IS 'TODO, ...';
|
||||
|
||||
DROP FUNCTION IF EXISTS api.log_geojson_fn;
|
||||
CREATE FUNCTION api.log_geojson_fn(IN _id INTEGER, OUT log_map JSON) RETURNS JSON AS $export_log$
|
||||
declare
|
||||
log_geojson jsonb;
|
||||
metrics_geojson jsonb;
|
||||
_map jsonb;
|
||||
begin
|
||||
-- GeoJson Feature Logbook linestring
|
||||
SELECT
|
||||
ST_AsGeoJSON(l.*) into log_geojson
|
||||
FROM
|
||||
api.logbook l
|
||||
WHERE l.id = _id;
|
||||
-- GeoJson Feature Metrics point
|
||||
SELECT
|
||||
json_agg(ST_AsGeoJSON(t.*)::json) into metrics_geojson
|
||||
FROM (
|
||||
(
|
||||
select
|
||||
time,
|
||||
courseovergroundtrue,
|
||||
speedoverground,
|
||||
anglespeedapparent,
|
||||
longitude,latitude,
|
||||
st_makepoint(longitude,latitude) AS geo_point
|
||||
FROM api.metrics m
|
||||
WHERE m.latitude IS NOT NULL
|
||||
AND m.longitude IS NOT NULL
|
||||
AND m.time >= '2022-08-27 20:00:34.000'
|
||||
AND m.time <= '2022-08-27 20:29:34.000'
|
||||
ORDER BY m.time asc
|
||||
)
|
||||
) AS t;
|
||||
|
||||
-- Add Linestring into Point array
|
||||
SELECT log_geojson::jsonb || metrics_geojson::jsonb into _map;
|
||||
|
||||
-- Build Geojson FeatureCollection
|
||||
SELECT
|
||||
json_build_object(
|
||||
'type', 'FeatureCollection',
|
||||
'features', _map
|
||||
) into log_map;
|
||||
END;
|
||||
$export_log$ LANGUAGE plpgsql;
|
||||
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.log_geojson_fn
|
||||
IS 'TODO';
|
||||
|
@@ -127,9 +127,8 @@ begin
|
||||
-- Gather email and pushover app settings
|
||||
app_settings = get_app_settings_fn();
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_metadata_fn(metadata_rec.id::INTEGER);
|
||||
--user_settings := get_user_settings_from_clientid_fn(metadata_rec.id::INTEGER);
|
||||
RAISE DEBUG '-> debug monitor_offline get_user_settings_from_metadata_fn [%]', user_settings;
|
||||
user_settings := get_user_settings_from_clientid_fn(metadata_rec.client_id::TEXT);
|
||||
RAISE DEBUG '-> debug monitor_offline get_user_settings_from_clientid_fn [%]', user_settings;
|
||||
-- Send notification
|
||||
--PERFORM send_notification_fn('monitor_offline'::TEXT, metadata_rec::RECORD);
|
||||
PERFORM send_email_py_fn('monitor_offline'::TEXT, user_settings::JSONB, app_settings::JSONB);
|
||||
@@ -172,9 +171,8 @@ begin
|
||||
-- Gather email and pushover app settings
|
||||
app_settings = get_app_settings_fn();
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_metadata_fn(metadata_rec.id::INTEGER);
|
||||
--user_settings := get_user_settings_from_clientid_fn((metadata_rec.client_id::INTEGER, );
|
||||
RAISE NOTICE '-> debug monitor_online get_user_settings_from_metadata_fn [%]', user_settings;
|
||||
user_settings := get_user_settings_from_clientid_fn(metadata_rec.client_id::TEXT);
|
||||
RAISE NOTICE '-> debug monitor_online get_user_settings_from_clientid_fn [%]', user_settings;
|
||||
-- Send notification
|
||||
--PERFORM send_notification_fn('monitor_online'::TEXT, metadata_rec::RECORD);
|
||||
PERFORM send_email_py_fn('monitor_online'::TEXT, user_settings::JSONB, app_settings::JSONB);
|
||||
|
@@ -82,12 +82,13 @@ COMMENT ON TABLE
|
||||
|
||||
-- with escape value, eg: E'A\nB\r\nC'
|
||||
-- https://stackoverflow.com/questions/26638615/insert-line-break-in-postgresql-when-updating-text-field
|
||||
-- TODO Update notification subject for log entry to 'logbook #NB ...'
|
||||
INSERT INTO email_templates VALUES
|
||||
('logbook',
|
||||
'New Logbook Entry',
|
||||
E'Hello __RECIPIENT__,\n\nWe just wanted to let you know that you have a new entry on openplotter.cloud: "__LOGBOOK_NAME__"\r\n\r\nSee more details at https://beta.openplotter.cloud/log/__LOGBOOK_LINK__\n\nHappy sailing!\nThe PostgSail Team',
|
||||
E'Hello __RECIPIENT__,\n\nWe just wanted to let you know that you have a new entry on openplotter.cloud: "__LOGBOOK_NAME__"\r\n\r\nSee more details at __APP_URL__/log/__LOGBOOK_LINK__\n\nHappy sailing!\nThe PostgSail Team',
|
||||
'New Logbook Entry',
|
||||
E'We just wanted to let you know that you have a new entry on openplotter.cloud: "__LOGBOOK_NAME__"\r\n\r\nSee more details at https://beta.openplotter.cloud/log/__LOGBOOK_LINK__\n\nHappy sailing!\nThe PostgSail Team'),
|
||||
E'We just wanted to let you know that you have a new entry on openplotter.cloud: "__LOGBOOK_NAME__"\r\n\r\nSee more details at __APP_URL__/log/__LOGBOOK_LINK__\n\nHappy sailing!\nThe PostgSail Team'),
|
||||
('user',
|
||||
'Welcome',
|
||||
E'Hello __RECIPIENT__,\nCongratulations!\nYou successfully created an account.\nKeep in mind to register your vessel.\nHappy sailing!',
|
||||
@@ -100,19 +101,19 @@ INSERT INTO email_templates VALUES
|
||||
E'Hi!\nHow are you?\n__BOAT__ is now linked to your account.'),
|
||||
('monitor_offline',
|
||||
'Offline',
|
||||
E'__BOAT__ has been offline for more than an hour\r\nFind more details at https://beta.openplotter.cloud/boats/\n',
|
||||
E'__BOAT__ has been offline for more than an hour\r\nFind more details at __APP_URL__/boats/\n',
|
||||
'Offline',
|
||||
E'__BOAT__ has been offline for more than an hour\r\nFind more details at https://beta.openplotter.cloud/boats/\n'),
|
||||
E'__BOAT__ has been offline for more than an hour\r\nFind more details at __APP_URL__/boats/\n'),
|
||||
('monitor_online',
|
||||
'Online',
|
||||
E'__BOAT__ just came online\nFind more details at https://beta.openplotter.cloud/boats/\n',
|
||||
E'__BOAT__ just came online\nFind more details at __APP_URL__/boats/\n',
|
||||
'Online',
|
||||
E'__BOAT__ just came online\nFind more details at https://beta.openplotter.cloud/boats/\n'),
|
||||
E'__BOAT__ just came online\nFind more details at __APP_URL__/boats/\n'),
|
||||
('badge',
|
||||
'New Badge!',
|
||||
E'Hello __RECIPIENT__,\nCongratulations! You have just unlocked a new badge: __BADGE_NAME__\nSee more details at https://beta.openplotter.cloud/badges\nHappy sailing!\nThe PostgSail Team',
|
||||
E'Hello __RECIPIENT__,\nCongratulations! You have just unlocked a new badge: __BADGE_NAME__\nSee more details at __APP_URL__/badges\nHappy sailing!\nThe PostgSail Team',
|
||||
'New Badge!',
|
||||
E'Congratulations!\nYou have just unlocked a new badge: __BADGE_NAME__\nSee more details at https://beta.openplotter.cloud/badges\nHappy sailing!\nThe PostgSail Team');
|
||||
E'Congratulations!\nYou have just unlocked a new badge: __BADGE_NAME__\nSee more details at __APP_URL__/badges\nHappy sailing!\nThe PostgSail Team');
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- python send email
|
||||
@@ -144,9 +145,9 @@ AS $send_email_py$
|
||||
email_content = rv[0]['email_content']
|
||||
|
||||
# Replace fields using input jsonb obj
|
||||
plpy.notice('Parameters [{}] [{}]'.format(_user, app))
|
||||
if not _user or not app:
|
||||
plpy.error('Error no parameters')
|
||||
plpy.notice('send_email_py_fn Parameters [{}] [{}]'.format(_user, app))
|
||||
plpy.error('Error missing parameters')
|
||||
return None
|
||||
if 'logbook_name' in _user and _user['logbook_name']:
|
||||
email_content = email_content.replace('__LOGBOOK_NAME__', _user['logbook_name'])
|
||||
@@ -159,6 +160,9 @@ AS $send_email_py$
|
||||
if 'badge' in _user and _user['badge']:
|
||||
email_content = email_content.replace('__BADGE_NAME__', _user['badge'])
|
||||
|
||||
if 'app.url' in app and app['app.url']:
|
||||
email_content = email_content.replace('__APP_URL__', app['app.url'])
|
||||
|
||||
email_from = 'root@localhost'
|
||||
if 'app.email_from' in app and app['app.email_from']:
|
||||
email_from = app['app.email_from']
|
||||
@@ -246,6 +250,9 @@ AS $send_pushover_py$
|
||||
if 'badge' in _user and _user['badge']:
|
||||
pushover_message = pushover_message.replace('__BADGE_NAME__', _user['badge'])
|
||||
|
||||
if 'app.url' in app and app['app.url']:
|
||||
pushover_message = pushover_message.replace('__APP_URL__', app['app.url'])
|
||||
|
||||
pushover_token = None
|
||||
if 'app.pushover_token' in app and app['app.pushover_token']:
|
||||
pushover_token = app['app.pushover_token']
|
||||
@@ -300,8 +307,9 @@ CREATE OR REPLACE FUNCTION logbook_update_avg_fn(
|
||||
SELECT AVG(speedOverGround), MAX(speedOverGround), MAX(windspeedapparent) INTO
|
||||
avg_speed, max_speed, max_wind_speed
|
||||
FROM api.metrics
|
||||
WHERE time >= _start::TIMESTAMP WITHOUT TIME ZONE AND
|
||||
time <= _end::TIMESTAMP WITHOUT TIME ZONE;
|
||||
WHERE time >= _start::TIMESTAMP WITHOUT TIME ZONE
|
||||
AND time <= _end::TIMESTAMP WITHOUT TIME ZONE
|
||||
AND client_id = current_setting('vessel.client_id', false);
|
||||
RAISE NOTICE '-> Updated avg for logbook id=%, avg_speed:%, max_speed:%, max_wind_speed:%', _id, avg_speed, max_speed, max_wind_speed;
|
||||
END;
|
||||
$logbook_update_avg$ LANGUAGE plpgsql;
|
||||
@@ -327,6 +335,7 @@ CREATE FUNCTION logbook_update_geom_distance_fn(IN _id integer, IN _start text,
|
||||
AND m.longitude IS NOT NULL
|
||||
AND m.time >= _start::TIMESTAMP WITHOUT TIME ZONE
|
||||
AND m.time <= _end::TIMESTAMP WITHOUT TIME ZONE
|
||||
AND client_id = current_setting('vessel.client_id', false)
|
||||
ORDER BY m.time ASC
|
||||
)
|
||||
) INTO _track_geom;
|
||||
@@ -373,13 +382,14 @@ CREATE FUNCTION logbook_update_geojson_fn(IN _id integer, IN _start text, IN _en
|
||||
AND m.longitude IS NOT NULL
|
||||
AND time >= _start::TIMESTAMP WITHOUT TIME ZONE
|
||||
AND time <= _end::TIMESTAMP WITHOUT TIME ZONE
|
||||
AND client_id = current_setting('vessel.client_id', false)
|
||||
ORDER BY m.time asc
|
||||
)
|
||||
) AS t;
|
||||
|
||||
--
|
||||
-- Merge jsonb
|
||||
select log_geojson::jsonb || metrics_geojson::jsonb into _map;
|
||||
|
||||
-- output
|
||||
SELECT
|
||||
json_build_object(
|
||||
'type', 'FeatureCollection',
|
||||
@@ -390,7 +400,7 @@ $logbook_geojson$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.logbook_update_geojson_fn
|
||||
IS 'Update logbook details with geojson';
|
||||
IS 'Update log details with geojson';
|
||||
|
||||
|
||||
-- Update pending new logbook from process queue
|
||||
@@ -403,8 +413,10 @@ CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void
|
||||
log_name varchar;
|
||||
avg_rec record;
|
||||
geo_rec record;
|
||||
log_settings jsonb;
|
||||
user_settings jsonb;
|
||||
app_settings jsonb;
|
||||
vessel_settings jsonb;
|
||||
geojson jsonb;
|
||||
BEGIN
|
||||
-- If _id is not NULL
|
||||
@@ -416,6 +428,9 @@ CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void
|
||||
WHERE active IS false
|
||||
AND id = _id;
|
||||
|
||||
PERFORM set_config('vessel.client_id', logbook_rec.client_id, false);
|
||||
RAISE WARNING 'public.process_logbook_queue_fn() scheduler vessel.client_id %', current_setting('vessel.client_id', false);
|
||||
|
||||
-- geo reverse _from_lng _from_lat
|
||||
-- geo reverse _to_lng _to_lat
|
||||
from_name := reverse_geocode_py_fn('nominatim', logbook_rec._from_lng::NUMERIC, logbook_rec._from_lat::NUMERIC);
|
||||
@@ -452,7 +467,11 @@ CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void
|
||||
-- Gather email and pushover app settings
|
||||
app_settings := get_app_settings_fn();
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_log_fn(logbook_rec::RECORD);
|
||||
SELECT json_build_object('logbook_name', log_name, 'logbook_link', logbook_rec.id) into log_settings;
|
||||
user_settings := get_user_settings_from_clientid_fn(logbook_rec.client_id::TEXT);
|
||||
SELECT user_settings::JSONB || log_settings::JSONB into user_settings;
|
||||
RAISE DEBUG '-> debug process_logbook_queue_fn get_user_settings_from_clientid_fn [%]', user_settings;
|
||||
--user_settings := get_user_settings_from_log_fn(logbook_rec::RECORD);
|
||||
--user_settings := '{"logbook_name": "' || log_name || '"}, "{"email": "' || account_rec.email || '", "recipient": "' || account_rec.first || '}';
|
||||
--user_settings := '{"logbook_name": "' || log_name || '"}';
|
||||
-- Send notification email, pushover
|
||||
@@ -473,7 +492,7 @@ CREATE OR REPLACE FUNCTION process_stay_queue_fn(IN _id integer) RETURNS void AS
|
||||
stay_rec record;
|
||||
_name varchar;
|
||||
BEGIN
|
||||
RAISE WARNING 'process_stay_queue_fn';
|
||||
RAISE NOTICE 'process_stay_queue_fn';
|
||||
-- If _id is not NULL
|
||||
IF _id IS NULL OR _id < 1 THEN
|
||||
RAISE WARNING '-> process_stay_queue_fn invalid input %', _id;
|
||||
@@ -481,7 +500,6 @@ CREATE OR REPLACE FUNCTION process_stay_queue_fn(IN _id integer) RETURNS void AS
|
||||
SELECT * INTO stay_rec
|
||||
FROM api.stays
|
||||
WHERE id = _id;
|
||||
-- AND client_id LIKE '%' || current_setting('vessel.mmsi', false) || '%';
|
||||
|
||||
-- geo reverse _lng _lat
|
||||
_name := reverse_geocode_py_fn('nominatim', stay_rec.longitude::NUMERIC, stay_rec.latitude::NUMERIC);
|
||||
@@ -510,6 +528,7 @@ CREATE OR REPLACE FUNCTION process_moorage_queue_fn(IN _id integer) RETURNS void
|
||||
stay_rec record;
|
||||
moorage_rec record;
|
||||
BEGIN
|
||||
RAISE NOTICE 'process_moorage_queue_fn';
|
||||
-- If _id is not NULL
|
||||
IF _id IS NULL OR _id < 1 THEN
|
||||
RAISE WARNING '-> process_moorage_queue_fn invalid input %', _id;
|
||||
@@ -590,10 +609,19 @@ CREATE OR REPLACE FUNCTION process_account_queue_fn(IN _email TEXT) RETURNS void
|
||||
user_settings jsonb;
|
||||
app_settings jsonb;
|
||||
BEGIN
|
||||
-- If _email is not NULL
|
||||
IF _email IS NULL OR _email = '' THEN
|
||||
RAISE EXCEPTION 'Invalid email'
|
||||
USING HINT = 'Unkown email';
|
||||
RETURN;
|
||||
END IF;
|
||||
SELECT * INTO account_rec
|
||||
FROM auth.accounts
|
||||
WHERE email = _email;
|
||||
IF account_rec.email IS NULL OR account_rec.email = '' THEN
|
||||
RAISE EXCEPTION 'Invalid email'
|
||||
USING HINT = 'Unkown email';
|
||||
RETURN;
|
||||
END IF;
|
||||
-- Gather email and pushover app settings
|
||||
app_settings := get_app_settings_fn();
|
||||
-- Gather user settings
|
||||
@@ -617,10 +645,19 @@ CREATE OR REPLACE FUNCTION process_vessel_queue_fn(IN _email TEXT) RETURNS void
|
||||
user_settings jsonb;
|
||||
app_settings jsonb;
|
||||
BEGIN
|
||||
-- If _email is not NULL
|
||||
IF _email IS NULL OR _email = '' THEN
|
||||
RAISE EXCEPTION 'Invalid email'
|
||||
USING HINT = 'Unkown email';
|
||||
RETURN;
|
||||
END IF;
|
||||
SELECT * INTO vessel_rec
|
||||
FROM auth.vessels
|
||||
WHERE owner_email = _email;
|
||||
IF vessel_rec.owner_email IS NULL OR vessel_rec.owner_email = '' THEN
|
||||
RAISE EXCEPTION 'Invalid email'
|
||||
USING HINT = 'Unkown email';
|
||||
RETURN;
|
||||
END IF;
|
||||
-- Gather user_settings from
|
||||
-- if notification email
|
||||
-- -- Send email
|
||||
@@ -643,79 +680,33 @@ COMMENT ON FUNCTION
|
||||
|
||||
-- Get user settings details from a log entry
|
||||
DROP FUNCTION IF EXISTS get_app_settings_fn;
|
||||
CREATE OR REPLACE FUNCTION get_app_settings_fn(OUT app_settings JSON) RETURNS JSON
|
||||
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%';
|
||||
END;
|
||||
$get_app_settings$ LANGUAGE plpgsql;
|
||||
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';
|
||||
END;
|
||||
$get_app_settings$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.get_app_settings_fn
|
||||
IS 'get app settings details, email, pushover';
|
||||
|
||||
|
||||
-- Get user settings details from a log entry
|
||||
DROP FUNCTION IF EXISTS get_user_settings_from_log_fn;
|
||||
CREATE OR REPLACE FUNCTION get_user_settings_from_log_fn(IN logbook_rec RECORD, OUT user_settings JSON) RETURNS JSON
|
||||
AS $get_user_settings_from_log$
|
||||
DECLARE
|
||||
BEGIN
|
||||
-- If client_id is not NULL
|
||||
IF logbook_rec.client_id IS NULL OR logbook_rec.client_id = '' THEN
|
||||
RAISE WARNING '-> get_user_settings_from_log_fn invalid input %', logbook_rec.client_id;
|
||||
END IF;
|
||||
SELECT
|
||||
json_build_object(
|
||||
'boat' , v.name,
|
||||
'recipient', a.first,
|
||||
'email', v.owner_email,
|
||||
'logbook_name', l.name,
|
||||
'logbook_link', l.id) INTO user_settings
|
||||
FROM auth.accounts a, auth.vessels v, api.metadata m, api.logbook l
|
||||
WHERE lower(a.email) = lower(v.owner_email)
|
||||
-- AND lower(v.name) = lower(m.name)
|
||||
AND m.client_id = l.client_id
|
||||
AND l.client_id = logbook_rec.client_id
|
||||
AND l.id = logbook_rec.id;
|
||||
|
||||
END;
|
||||
$get_user_settings_from_log$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.get_user_settings_from_log_fn
|
||||
IS 'get user settings details from a log entry, initiate for logbook entry notification';
|
||||
|
||||
-- Get user settings details from a metadata entry
|
||||
DROP FUNCTION IF EXISTS get_user_settings_from_metadata;
|
||||
CREATE OR REPLACE FUNCTION get_user_settings_from_metadata_fn(IN meta_id INTEGER, OUT user_settings JSON) RETURNS JSON
|
||||
AS $get_user_settings_from_metadata$
|
||||
DECLARE
|
||||
BEGIN
|
||||
-- If meta_id is not NULL
|
||||
IF meta_id IS NULL OR meta_id < 1 THEN
|
||||
RAISE WARNING '-> get_user_settings_from_metadata_fn invalid input %', meta_id;
|
||||
END IF;
|
||||
SELECT json_build_object(
|
||||
'boat' , v.name,
|
||||
'email', v.owner_email) INTO user_settings
|
||||
FROM auth.vessels v, api.metadata m
|
||||
WHERE
|
||||
--lower(v.name) = lower(m.name) AND
|
||||
m.id = meta_id;
|
||||
END;
|
||||
$get_user_settings_from_metadata$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.get_user_settings_from_metadata_fn
|
||||
IS 'get user settings details from a metadata entry, initiate for monitoring offline,online notification';
|
||||
|
||||
-- Get user settings details from a metadata entry
|
||||
-- Send notifications
|
||||
DROP FUNCTION IF EXISTS send_notification_fn;
|
||||
CREATE OR REPLACE FUNCTION send_notification_fn(IN email_type TEXT, IN notification_rec RECORD) RETURNS JSON
|
||||
CREATE OR REPLACE FUNCTION send_notification_fn(
|
||||
IN email_type TEXT,
|
||||
IN user_settings JSONB) RETURNS VOID
|
||||
AS $send_notification$
|
||||
DECLARE
|
||||
app_settings JSONB;
|
||||
@@ -738,19 +729,18 @@ $send_notification$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.send_notification_fn
|
||||
IS 'TODO';
|
||||
IS 'TODO Send notifications';
|
||||
|
||||
DROP FUNCTION IF EXISTS get_user_settings_from_clientid_fn;
|
||||
CREATE OR REPLACE FUNCTION get_user_settings_from_clientid_fn(
|
||||
IN clientid TEXT,
|
||||
IN logbook_name TEXT,
|
||||
OUT user_settings JSON
|
||||
) RETURNS JSON
|
||||
OUT user_settings JSONB
|
||||
) RETURNS JSONB
|
||||
AS $get_user_settings_from_clientid$
|
||||
DECLARE
|
||||
BEGIN
|
||||
-- If client_id is not NULL
|
||||
IF clientid IS NULL OR clientid <> '' THEN
|
||||
IF clientid IS NULL OR clientid = '' THEN
|
||||
RAISE WARNING '-> get_user_settings_from_clientid_fn invalid input %', clientid;
|
||||
END IF;
|
||||
SELECT
|
||||
@@ -760,19 +750,49 @@ AS $get_user_settings_from_clientid$
|
||||
'email', v.owner_email ,
|
||||
'settings', a.preferences,
|
||||
'pushover_key', a.preferences->'pushover_key',
|
||||
'badges', a.preferences->'badges',
|
||||
'logbook_name', logbook_name ) INTO user_settings
|
||||
'badges', a.preferences->'badges'
|
||||
) INTO user_settings
|
||||
FROM auth.accounts a, auth.vessels v, api.metadata m
|
||||
WHERE lower(a.email) = lower(v.owner_email)
|
||||
--AND lower(v.name) = lower(m.name)
|
||||
AND m.mmsi = v.mmsi
|
||||
WHERE m.mmsi = v.mmsi
|
||||
AND m.client_id = clientid;
|
||||
END;
|
||||
$get_user_settings_from_clientid$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.get_user_settings_from_clientid_fn
|
||||
IS 'get user settings details from a clientid, initiate for badge entry notification';
|
||||
IS 'get user settings details from a clientid, initiate for notifications';
|
||||
|
||||
DROP FUNCTION IF EXISTS set_vessel_settings_from_clientid_fn;
|
||||
CREATE OR REPLACE FUNCTION set_vessel_settings_from_clientid_fn(
|
||||
IN clientid TEXT,
|
||||
OUT vessel_settings JSONB
|
||||
) RETURNS JSONB
|
||||
AS $set_vessel_settings_from_clientid$
|
||||
DECLARE
|
||||
BEGIN
|
||||
-- If client_id is not NULL
|
||||
IF clientid IS NULL OR clientid = '' THEN
|
||||
RAISE WARNING '-> set_vessel_settings_from_clientid_fn invalid input %', clientid;
|
||||
END IF;
|
||||
SELECT
|
||||
json_build_object(
|
||||
'name' , v.name,
|
||||
'mmsi', v.mmsi,
|
||||
'client_id', m.client_id
|
||||
) INTO vessel_settings
|
||||
FROM auth.accounts a, auth.vessels v, api.metadata m
|
||||
WHERE m.mmsi = v.mmsi
|
||||
AND m.client_id = clientid;
|
||||
PERFORM set_config('vessel.mmsi', vessel_rec.mmsi, false);
|
||||
PERFORM set_config('vessel.name', vessel_rec.name, false);
|
||||
PERFORM set_config('vessel.client_id', vessel_rec.client_id, false);
|
||||
END;
|
||||
$set_vessel_settings_from_clientid$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.set_vessel_settings_from_clientid_fn
|
||||
IS 'set_vessel settings details from a clientid, initiate for process queue functions';
|
||||
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Queue handling
|
||||
@@ -923,6 +943,7 @@ DECLARE
|
||||
_role name;
|
||||
_email name;
|
||||
_mmsi name;
|
||||
_path name;
|
||||
account_rec record;
|
||||
vessel_rec record;
|
||||
BEGIN
|
||||
@@ -939,7 +960,16 @@ BEGIN
|
||||
WHERE auth.accounts.email = _email;
|
||||
IF account_rec.email IS NULL THEN
|
||||
RAISE EXCEPTION 'Invalid user'
|
||||
USING HINT = 'Unkown user';
|
||||
USING HINT = 'Unkown user or password';
|
||||
END IF;
|
||||
RAISE WARNING 'req path %', current_setting('request.path', true);
|
||||
-- Function allow without defined vessel
|
||||
-- openapi doc, user settings and vessel registration
|
||||
SELECT current_setting('request.path', true) into _path;
|
||||
IF _path = '/rpc/settings_fn'
|
||||
OR _path = '/rpc/register_vessel'
|
||||
OR _path = '/' THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
-- Check a vessel and user exist
|
||||
SELECT * INTO vessel_rec
|
||||
@@ -948,7 +978,12 @@ BEGIN
|
||||
AND auth.accounts.email = _email;
|
||||
-- check if boat exist yet?
|
||||
IF vessel_rec.owner_email IS NULL THEN
|
||||
RETURN; -- ignore if not exist
|
||||
-- Return http status code 551 with message
|
||||
RAISE sqlstate 'PT551' using
|
||||
message = 'Vessel Required',
|
||||
detail = 'Invalid vessel',
|
||||
hint = 'Unkown vessel';
|
||||
--RETURN; -- ignore if not exist
|
||||
END IF;
|
||||
IF vessel_rec.mmsi IS NULL THEN
|
||||
RAISE EXCEPTION 'Invalid vessel'
|
||||
|
132
initdb/02_5_signalk_api_deps.sql
Normal file
132
initdb/02_5_signalk_api_deps.sql
Normal file
@@ -0,0 +1,132 @@
|
||||
---------------------------------------------------------------------------
|
||||
-- singalk db permissions
|
||||
--
|
||||
|
||||
-- List current database
|
||||
select current_database();
|
||||
|
||||
-- connect to the DB
|
||||
\c signalk
|
||||
|
||||
-- List vessel
|
||||
--TODO add geojson with position
|
||||
DROP VIEW IF EXISTS api.vessels_view;
|
||||
CREATE OR REPLACE VIEW api.vessels_view AS
|
||||
SELECT
|
||||
v.name as name,
|
||||
v.mmsi as mmsi,
|
||||
v.created_at as created_at,
|
||||
coalesce(m.time, null) as last_contact
|
||||
FROM auth.vessels v, api.metadata m
|
||||
WHERE
|
||||
m.mmsi = current_setting('vessel.mmsi')
|
||||
AND m.mmsi = v.mmsi
|
||||
AND lower(v.owner_email) = lower(current_setting('request.jwt.claims', true)::json->>'email');
|
||||
|
||||
DROP VIEW IF EXISTS api.vessel_p_view;
|
||||
CREATE OR REPLACE VIEW api.vessel_p_view AS
|
||||
SELECT
|
||||
v.name as name,
|
||||
v.mmsi as mmsi,
|
||||
v.created_at as created_at,
|
||||
null as last_contact
|
||||
FROM auth.vessels v
|
||||
WHERE lower(v.owner_email) = lower(current_setting('request.jwt.claims', true)::json->>'email');
|
||||
|
||||
-- Or function?
|
||||
DROP FUNCTION IF EXISTS api.vessel_fn;
|
||||
CREATE OR REPLACE FUNCTION api.vessel_fn(OUT vessel JSON) RETURNS JSON
|
||||
AS $vessel$
|
||||
DECLARE
|
||||
BEGIN
|
||||
SELECT
|
||||
json_build_object(
|
||||
'name', v.name,
|
||||
'mmsi', v.mmsi,
|
||||
'created_at', v.created_at,
|
||||
'last_contact', m.time,
|
||||
'geojson', ST_AsGeoJSON(geojson_t.*)::json
|
||||
)
|
||||
INTO vessel
|
||||
FROM auth.vessels v, api.metadata m,
|
||||
( SELECT
|
||||
t.*
|
||||
FROM (
|
||||
( select
|
||||
current_setting('vessel.name') as name,
|
||||
time,
|
||||
courseovergroundtrue,
|
||||
speedoverground,
|
||||
anglespeedapparent,
|
||||
longitude,latitude,
|
||||
st_makepoint(longitude,latitude) AS geo_point
|
||||
FROM public.last_metric
|
||||
WHERE
|
||||
latitude IS NOT NULL
|
||||
AND longitude IS NOT NULL
|
||||
AND client_id LIKE '%' || current_setting('vessel.mmsi', false)
|
||||
)
|
||||
) AS t
|
||||
) AS geojson_t
|
||||
WHERE
|
||||
m.mmsi = current_setting('vessel.mmsi')
|
||||
AND m.mmsi = v.mmsi;
|
||||
--RAISE notice 'api.vessel_fn %', obj;
|
||||
END;
|
||||
$vessel$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.vessel_fn
|
||||
IS 'Expose vessel details to API';
|
||||
|
||||
-- Export user settings
|
||||
DROP FUNCTION IF EXISTS api.settings_fn;
|
||||
CREATE FUNCTION api.settings_fn(out settings json) RETURNS JSON
|
||||
AS $user_settings$
|
||||
BEGIN
|
||||
select row_to_json(row)::json INTO settings
|
||||
from (
|
||||
select email,first,last,preferences,created_at,
|
||||
INITCAP(CONCAT (LEFT(first, 1), ' ', last)) AS username
|
||||
from auth.accounts
|
||||
where lower(email) = lower(current_setting('request.jwt.claims', true)::json->>'email')
|
||||
) row;
|
||||
END;
|
||||
$user_settings$ language plpgsql security definer;
|
||||
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.settings_fn
|
||||
IS 'Expose user settings to API';
|
||||
|
||||
DROP FUNCTION IF EXISTS api.versions_fn;
|
||||
CREATE OR REPLACE FUNCTION api.versions_fn() RETURNS JSON
|
||||
AS $version$
|
||||
DECLARE
|
||||
_appv TEXT;
|
||||
_sysv TEXT;
|
||||
BEGIN
|
||||
SELECT
|
||||
value, version() into _appv,_sysv
|
||||
FROM app_settings
|
||||
WHERE name = 'app.version';
|
||||
RETURN json_build_object('app_version', _appv,
|
||||
'sys_version', _sysv);
|
||||
END;
|
||||
$version$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.versions_fn
|
||||
IS 'Expose function app and system version to API';
|
||||
|
||||
DROP VIEW IF EXISTS api.versions_view;
|
||||
CREATE OR REPLACE VIEW api.versions_view AS
|
||||
SELECT
|
||||
value as app_version,
|
||||
version() as sys_version
|
||||
FROM app_settings
|
||||
WHERE name = 'app.version';
|
||||
-- Description
|
||||
COMMENT ON VIEW
|
||||
api.versions_view
|
||||
IS 'Expose view app and system version to API';
|
@@ -15,7 +15,7 @@ select current_database();
|
||||
--
|
||||
-- api_anonymous
|
||||
-- nologin
|
||||
-- api_anonymous role in the database with which to execute anonymous web requests.
|
||||
-- api_anonymous role in the database with which to execute anonymous web requests, limit 10 connections
|
||||
-- api_anonymous allows JWT token generation with an expiration time via function api.login() from auth.accounts table
|
||||
create role api_anonymous WITH NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOLOGIN NOBYPASSRLS NOREPLICATION CONNECTION LIMIT 10;
|
||||
-- Limit to 10 connections
|
||||
@@ -39,10 +39,11 @@ GRANT USAGE, SELECT ON SEQUENCE api.logbook_id_seq,api.metadata_id_seq,api.moora
|
||||
GRANT SELECT ON TABLE api.metrics,api.logbook,api.moorages,api.stays,api.metadata TO grafana;
|
||||
-- Allow read on VIEWS
|
||||
GRANT SELECT ON TABLE api.logs_view,api.moorages_view,api.stays_view TO grafana;
|
||||
--GRANT SELECT ON TABLE api.logs_view,api.moorages_view,api.stays_view,api.vessels_view TO grafana;
|
||||
|
||||
-- User:
|
||||
-- nologin
|
||||
-- read-only for all and Read-Write on logbook, stays and moorage except for specific (name, notes) COLUMNS ?
|
||||
-- nologin, web api only
|
||||
-- read-only for all and Read-Write on logbook, stays and moorage except for specific (name, notes) COLUMNS
|
||||
CREATE ROLE user_role WITH NOLOGIN NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOBYPASSRLS NOREPLICATION;
|
||||
GRANT user_role to authenticator;
|
||||
GRANT USAGE ON SCHEMA api TO user_role;
|
||||
@@ -57,70 +58,37 @@ GRANT UPDATE (name, notes, stay_code) ON api.stays TO user_role;
|
||||
GRANT UPDATE (name, notes, stay_code, home_flag) ON api.moorages TO user_role;
|
||||
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA api TO user_role;
|
||||
-- explicitly limit EXECUTE privileges to pgrest db-pre-request function
|
||||
GRANT EXECUTE ON FUNCTION api.export_logbook_geojson_linestring_fn(int4) TO user_role;
|
||||
GRANT EXECUTE ON FUNCTION public.check_jwt() TO user_role;
|
||||
GRANT EXECUTE ON FUNCTION public.st_asgeojson(text) TO user_role;
|
||||
GRANT EXECUTE ON FUNCTION public.geography_eq(geography, geography) TO user_role;
|
||||
-- TODO should not be need !! ??
|
||||
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public TO user_role;
|
||||
|
||||
-- Update ownership for security user_role as run by web user.
|
||||
-- Web listing
|
||||
ALTER VIEW api.stays_view OWNER TO user_role;
|
||||
ALTER VIEW api.moorages_view OWNER TO user_role;
|
||||
ALTER VIEW api.logs_view OWNER TO user_role;
|
||||
-- Remove all right except select
|
||||
ALTER VIEW api.vessel_p_view OWNER TO user_role;
|
||||
-- Remove all permissions except select
|
||||
REVOKE UPDATE, TRUNCATE, REFERENCES, DELETE, TRIGGER, INSERT ON TABLE api.stays_view FROM user_role;
|
||||
REVOKE UPDATE, TRUNCATE, REFERENCES, DELETE, TRIGGER, INSERT ON TABLE api.moorages_view FROM user_role;
|
||||
REVOKE UPDATE, TRUNCATE, REFERENCES, DELETE, TRIGGER, INSERT ON TABLE api.logs_view FROM user_role;
|
||||
--REVOKE UPDATE, TRUNCATE, REFERENCES, DELETE, TRIGGER, INSERT ON TABLE api.vessel_view FROM user_role;
|
||||
|
||||
-- Allow read and update on VIEWS
|
||||
ALTER VIEW api.logs_view OWNER TO user_role;
|
||||
REVOKE TRUNCATE, DELETE, TRIGGER, INSERT ON TABLE api.stays_view FROM user_role;
|
||||
-- Web detail view
|
||||
ALTER VIEW api.log_view OWNER TO user_role;
|
||||
-- Remove all permissions except select and update
|
||||
REVOKE TRUNCATE, DELETE, TRIGGER, INSERT ON TABLE api.log_view FROM user_role;
|
||||
|
||||
-- For cron job
|
||||
GRANT EXECUTE ON function api.run_cron_jobs() TO user_role;
|
||||
ALTER VIEW api.vessels_view OWNER TO user_role;
|
||||
-- Remove all permissions except select and update
|
||||
REVOKE TRUNCATE, DELETE, TRIGGER, INSERT ON TABLE api.vessels_view FROM user_role;
|
||||
ALTER VIEW api.vessel_p_view OWNER TO user_role;
|
||||
-- Remove all permissions except select and update
|
||||
REVOKE TRUNCATE, DELETE, TRIGGER, INSERT ON TABLE api.vessel_p_view FROM user_role;
|
||||
|
||||
-- List vessel
|
||||
CREATE OR REPLACE VIEW api.vessel_view AS
|
||||
SELECT
|
||||
v.name as name,
|
||||
v.mmsi as mmsi,
|
||||
v.created_at as created_at,
|
||||
m.time as last_contact
|
||||
FROM auth.vessels v, api.metadata m
|
||||
WHERE
|
||||
m.mmsi = current_setting('vessel.mmsi')
|
||||
AND lower(v.owner_email) = lower(current_setting('request.jwt.claims', true)::json->>'email');
|
||||
|
||||
ALTER VIEW api.vessel_view OWNER TO user_role;
|
||||
REVOKE UPDATE, TRUNCATE, REFERENCES, DELETE, TRIGGER, INSERT ON TABLE api.vessel_view FROM user_role;
|
||||
GRANT SELECT ON TABLE api.logs_view,api.moorages_view,api.stays_view,api.vessel_view TO grafana;
|
||||
|
||||
-- Or function?
|
||||
DROP FUNCTION IF EXISTS api.vessel_fn;
|
||||
CREATE OR REPLACE FUNCTION api.vessel_fn(OUT obj JSON) RETURNS JSON
|
||||
AS $vessel$
|
||||
DECLARE
|
||||
_email name;
|
||||
BEGIN
|
||||
SELECT current_setting('request.jwt.claims', true)::json->>'email' INTO _email;
|
||||
-- todo check if valid email
|
||||
SELECT
|
||||
v.name as name,
|
||||
v.mmsi as mmsi,
|
||||
v.created_at as created_at,
|
||||
m.time as last_contact
|
||||
FROM auth.vessels v, api.metadata m
|
||||
WHERE
|
||||
m.mmsi = v.mmsi
|
||||
AND lower(v.owner_email) = lower(_email);
|
||||
END;
|
||||
$vessel$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.vessel_fn
|
||||
IS 'TODO, ...';
|
||||
|
||||
-- Allow read on VIEWS
|
||||
--GRANT SELECT ON TABLE api.logs_view,api.moorages_view,api.stays_view,api.vessel_view TO user_role;
|
||||
|
||||
-- Vessel:
|
||||
-- nologin
|
||||
@@ -135,12 +103,16 @@ GRANT USAGE, SELECT ON SEQUENCE public.process_queue_id_seq TO vessel_role;
|
||||
-- explicitly limit EXECUTE privileges to pgrest db-pre-request function
|
||||
GRANT EXECUTE ON FUNCTION public.check_jwt() to vessel_role;
|
||||
|
||||
--- Scheduler:
|
||||
-- TODO: currently cron function are run as super user, switch to scheduler role.
|
||||
-- Scheduler read-only all, and write on logbook, stays, moorage, process_queue
|
||||
-- Crons
|
||||
CREATE ROLE scheduler WITH NOLOGIN;
|
||||
--CREATE ROLE scheduler WITH NOLOGIN NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOBYPASSRLS NOREPLICATION;
|
||||
CREATE ROLE scheduler WITH NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOBYPASSRLS NOREPLICATION CONNECTION LIMIT 10 LOGIN;
|
||||
GRANT scheduler to authenticator;
|
||||
GRANT EXECUTE ON FUNCTION api.run_cron_jobs() to scheduler;
|
||||
GRANT USAGE ON SCHEMA api TO scheduler;
|
||||
GRANT SELECT ON TABLE api.metrics,api.metadata TO scheduler;
|
||||
GRANT INSERT, UPDATE, SELECT ON TABLE api.logbook,api.moorages,api.stays TO scheduler;
|
||||
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public TO scheduler;
|
||||
GRANT SELECT ON ALL TABLES IN SCHEMA public TO scheduler;
|
||||
GRANT SELECT,UPDATE ON TABLE process_queue TO scheduler;
|
||||
@@ -164,6 +136,10 @@ CREATE POLICY api_vessel_role ON api.metadata TO vessel_role
|
||||
CREATE POLICY api_user_role ON api.metadata TO user_role
|
||||
USING (client_id LIKE '%' || current_setting('vessel.mmsi', false) || '%')
|
||||
WITH CHECK (client_id LIKE '%' || current_setting('vessel.mmsi', false) || '%');
|
||||
-- Allow scheduler to update and select based on the client_id
|
||||
CREATE POLICY api_scheduler_role ON api.metadata TO scheduler
|
||||
USING (client_id = current_setting('vessel.client_id', false))
|
||||
WITH CHECK (client_id = current_setting('vessel.client_id', false));
|
||||
|
||||
ALTER TABLE api.metrics ENABLE ROW LEVEL SECURITY;
|
||||
-- Administrator can see all rows and add any rows
|
||||
@@ -178,6 +154,10 @@ CREATE POLICY api_vessel_role ON api.metrics TO vessel_role
|
||||
CREATE POLICY api_user_role ON api.metrics TO user_role
|
||||
USING (client_id LIKE '%' || current_setting('vessel.mmsi', false) || '%')
|
||||
WITH CHECK (client_id LIKE '%' || current_setting('vessel.mmsi', false) || '%');
|
||||
-- Allow scheduler to update and select based on the client_id
|
||||
CREATE POLICY api_scheduler_role ON api.metrics TO scheduler
|
||||
USING (client_id = current_setting('vessel.client_id', false))
|
||||
WITH CHECK (client_id = current_setting('vessel.client_id', false));
|
||||
|
||||
-- Be sure to enable row level security on the table
|
||||
ALTER TABLE api.logbook ENABLE ROW LEVEL SECURITY;
|
||||
@@ -194,6 +174,10 @@ CREATE POLICY api_vessel_role ON api.logbook TO vessel_role
|
||||
CREATE POLICY api_user_role ON api.logbook TO user_role
|
||||
USING (client_id LIKE '%' || current_setting('vessel.mmsi', false) || '%')
|
||||
WITH CHECK (client_id LIKE '%' || current_setting('vessel.mmsi', false) || '%');
|
||||
-- Allow scheduler to update and select based on the client_id
|
||||
CREATE POLICY api_scheduler_role ON api.logbook TO scheduler
|
||||
USING (client_id = current_setting('vessel.client_id', false))
|
||||
WITH CHECK (client_id = current_setting('vessel.client_id', false));
|
||||
|
||||
-- Be sure to enable row level security on the table
|
||||
ALTER TABLE api.stays ENABLE ROW LEVEL SECURITY;
|
||||
@@ -209,6 +193,10 @@ CREATE POLICY api_vessel_role ON api.stays TO vessel_role
|
||||
CREATE POLICY api_user_role ON api.stays TO user_role
|
||||
USING (client_id LIKE '%' || current_setting('vessel.mmsi', false) || '%')
|
||||
WITH CHECK (client_id LIKE '%' || current_setting('vessel.mmsi', false) || '%');
|
||||
-- Allow scheduler to update and select based on the client_id
|
||||
CREATE POLICY api_scheduler_role ON api.stays TO scheduler
|
||||
USING (client_id = current_setting('vessel.client_id', false))
|
||||
WITH CHECK (client_id = current_setting('vessel.client_id', false));
|
||||
|
||||
-- Be sure to enable row level security on the table
|
||||
ALTER TABLE api.moorages ENABLE ROW LEVEL SECURITY;
|
||||
@@ -224,6 +212,10 @@ CREATE POLICY api_vessel_role ON api.moorages TO vessel_role
|
||||
CREATE POLICY api_user_role ON api.moorages TO user_role
|
||||
USING (client_id LIKE '%' || current_setting('vessel.mmsi', false) || '%')
|
||||
WITH CHECK (client_id LIKE '%' || current_setting('vessel.mmsi', false) || '%');
|
||||
-- Allow scheduler to update and select based on the client_id
|
||||
CREATE POLICY api_scheduler_role ON api.moorages TO scheduler
|
||||
USING (client_id = current_setting('vessel.client_id', false))
|
||||
WITH CHECK (client_id = current_setting('vessel.client_id', false));
|
||||
|
||||
-- Be sure to enable row level security on the table
|
||||
ALTER TABLE auth.vessels ENABLE ROW LEVEL SECURITY;
|
||||
@@ -238,4 +230,4 @@ CREATE POLICY api_user_role ON auth.vessels TO user_role
|
||||
)
|
||||
WITH CHECK (mmsi = current_setting('vessel.mmsi', false)
|
||||
AND owner_email = current_setting('request.jwt.claims', false)::json->>'email'
|
||||
)
|
||||
);
|
@@ -16,6 +16,7 @@ INSERT INTO app_settings (name, value) VALUES
|
||||
('app.email_from', '${PGSAIL_EMAIL_FROM}'),
|
||||
('app.pushover_token', '${PGSAIL_PUSHOVER_TOKEN}'),
|
||||
('app.pushover_app', '_todo_'),
|
||||
('app.url', '${PGSAIL_APP_URL}'),
|
||||
('app.version', '${PGSAIL_VERSION}');
|
||||
-- Update comment with version
|
||||
COMMENT ON DATABASE signalk IS 'version ${PGSAIL_VERSION}';
|
||||
|
@@ -1 +1 @@
|
||||
0.0.5
|
||||
0.0.8
|
||||
|
Reference in New Issue
Block a user