mirror of
https://github.com/xbgmsharp/postgsail.git
synced 2025-09-18 03:37:47 +00:00
Compare commits
5 Commits
Author | SHA1 | Date | |
---|---|---|---|
![]() |
91d4127405 | ||
![]() |
6315dca4b9 | ||
![]() |
c35f353329 | ||
![]() |
54942a7558 | ||
![]() |
9a86c9f4f5 |
@@ -1,5 +1,5 @@
|
|||||||
# PostgSail
|
# PostgSail
|
||||||
Effortless cloud based solution for storing and sharing your SignalK data. Allow to effortlessly log your sails and monitor your boat.
|
Effortless cloud based solution for storing and sharing your SignalK data. Allow to effortlessly log your sails and monitor your boat with historical data.
|
||||||
|
|
||||||
### Context
|
### 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 database with a bit python.
|
||||||
@@ -38,7 +38,7 @@ Then simply excecute:
|
|||||||
$ docker-compose up
|
$ docker-compose up
|
||||||
```
|
```
|
||||||
|
|
||||||
### PostgSail Configuration
|
### SQL Configuration
|
||||||
|
|
||||||
Check and update your postgsail settings via SQL in the table `app_settings`:
|
Check and update your postgsail settings via SQL in the table `app_settings`:
|
||||||
|
|
||||||
@@ -58,7 +58,7 @@ Next, to ingest data from signalk, you need to install [signalk-postgsail](https
|
|||||||
|
|
||||||
Also, if you like, you can import saillogger data using the postgsail helpers, [postgsail-helpers](https://github.com/xbgmsharp/postgsail-helpers).
|
Also, if you like, you can import saillogger data using the postgsail helpers, [postgsail-helpers](https://github.com/xbgmsharp/postgsail-helpers).
|
||||||
|
|
||||||
You might want to import your influxdb1 data as weel, [outflux](https://github.com/timescale/outflux).
|
You might want to import your influxdb1 data as well, [outflux](https://github.com/timescale/outflux).
|
||||||
Any taker on influxdb2 to PostgSail? It is definitly possible.
|
Any taker on influxdb2 to PostgSail? It is definitly possible.
|
||||||
|
|
||||||
Last, if you like, you can import the sample data from Signalk NMEA Plaka by running the tests.
|
Last, if you like, you can import the sample data from Signalk NMEA Plaka by running the tests.
|
||||||
|
@@ -15,7 +15,7 @@
|
|||||||
-- Always store time in UTC
|
-- Always store time in UTC
|
||||||
---------------------------------------------------------------------------
|
---------------------------------------------------------------------------
|
||||||
|
|
||||||
-- vessels signalk -(POST)-> metadata -> metadata_upsert -(trigger)-> metadata_upsert_fn (INSERT or UPDATE)
|
-- vessels signalk -(POST)-> metadata -> metadata_upsert -(trigger)-> metadata_upsert_trigger_fn (INSERT or UPDATE)
|
||||||
-- vessels signalk -(POST)-> metrics -> metrics -(trigger)-> metrics_fn new log,stay,moorage
|
-- vessels signalk -(POST)-> metrics -> metrics -(trigger)-> metrics_fn new log,stay,moorage
|
||||||
|
|
||||||
---------------------------------------------------------------------------
|
---------------------------------------------------------------------------
|
||||||
@@ -151,6 +151,7 @@ CREATE TABLE IF NOT EXISTS api.logbook(
|
|||||||
--track_geom Geometry(LINESTRING)
|
--track_geom Geometry(LINESTRING)
|
||||||
track_geom geometry(LINESTRING,4326) NULL,
|
track_geom geometry(LINESTRING,4326) NULL,
|
||||||
track_geog geography(LINESTRING) NULL,
|
track_geog geography(LINESTRING) NULL,
|
||||||
|
track_geojson JSON NULL,
|
||||||
_from_time TIMESTAMP WITHOUT TIME ZONE NOT NULL,
|
_from_time TIMESTAMP WITHOUT TIME ZONE NOT NULL,
|
||||||
_to_time TIMESTAMP WITHOUT TIME ZONE NULL,
|
_to_time TIMESTAMP WITHOUT TIME ZONE NULL,
|
||||||
distance NUMERIC, -- meters?
|
distance NUMERIC, -- meters?
|
||||||
@@ -604,6 +605,8 @@ COMMENT ON FUNCTION
|
|||||||
|
|
||||||
---------------------------------------------------------------------------
|
---------------------------------------------------------------------------
|
||||||
-- Views
|
-- Views
|
||||||
|
-- Views are invoked with the privileges of the view owner,
|
||||||
|
-- make the user_role the view’s owner.
|
||||||
--
|
--
|
||||||
CREATE VIEW first_metric AS
|
CREATE VIEW first_metric AS
|
||||||
SELECT *
|
SELECT *
|
||||||
@@ -628,16 +631,46 @@ CREATE VIEW stay_in_progress AS
|
|||||||
-- TODO: Use materialized views instead as it is not live data
|
-- TODO: Use materialized views instead as it is not live data
|
||||||
-- Logs web view
|
-- Logs web view
|
||||||
DROP VIEW IF EXISTS api.logs_view;
|
DROP VIEW IF EXISTS api.logs_view;
|
||||||
CREATE VIEW api.logs_view AS
|
CREATE OR REPLACE VIEW api.logs_view AS
|
||||||
SELECT id,name,_from,_to,_from_time,_to_time,distance,duration
|
SELECT id,
|
||||||
FROM api.logbook
|
name as "Name",
|
||||||
WHERE _to_time IS NOT NULL
|
_from as "From",
|
||||||
ORDER BY _from_time DESC;
|
_from_time as "Started",
|
||||||
|
_to as "To",
|
||||||
|
_to_time as "Ended",
|
||||||
|
distance as "Distance",
|
||||||
|
duration as "Duration"
|
||||||
|
FROM api.logbook l
|
||||||
|
WHERE _to_time IS NOT NULL
|
||||||
|
ORDER BY _from_time DESC;
|
||||||
-- Description
|
-- Description
|
||||||
COMMENT ON VIEW
|
COMMENT ON VIEW
|
||||||
api.logs_view
|
api.logs_view
|
||||||
IS 'Logs web view';
|
IS 'Logs web view';
|
||||||
|
|
||||||
|
DROP VIEW IF EXISTS api.log_view;
|
||||||
|
CREATE OR REPLACE VIEW api.log_view AS
|
||||||
|
SELECT id,
|
||||||
|
name as "Name",
|
||||||
|
_from as "From",
|
||||||
|
_from_time as "Started",
|
||||||
|
_to as "To",
|
||||||
|
_to_time as "Ended",
|
||||||
|
distance as "Distance",
|
||||||
|
duration as "Duration",
|
||||||
|
notes as "Notes",
|
||||||
|
track_geojson as geojson,
|
||||||
|
avg_speed as avg_speed,
|
||||||
|
max_speed as max_speed,
|
||||||
|
max_wind_speed as max_wind_speed
|
||||||
|
FROM api.logbook l
|
||||||
|
WHERE _to_time IS NOT NULL
|
||||||
|
ORDER BY _from_time DESC;
|
||||||
|
-- Description
|
||||||
|
COMMENT ON VIEW
|
||||||
|
api.logs_view
|
||||||
|
IS 'Log web view';
|
||||||
|
|
||||||
-- Stays web view
|
-- Stays web view
|
||||||
-- TODO group by month
|
-- TODO group by month
|
||||||
DROP VIEW IF EXISTS api.stays_view;
|
DROP VIEW IF EXISTS api.stays_view;
|
||||||
@@ -894,3 +927,54 @@ COMMENT ON FUNCTION
|
|||||||
--COMMENT ON FUNCTION
|
--COMMENT ON FUNCTION
|
||||||
-- api.export_logbook_csv_fn
|
-- api.export_logbook_csv_fn
|
||||||
-- IS 'TODO, ...';
|
-- 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';
|
||||||
|
@@ -85,9 +85,9 @@ COMMENT ON TABLE
|
|||||||
INSERT INTO email_templates VALUES
|
INSERT INTO email_templates VALUES
|
||||||
('logbook',
|
('logbook',
|
||||||
'New Logbook Entry',
|
'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 __LOGBOOK_LINK__\n\nHappy sailing!\nThe Saillogger 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 https://beta.openplotter.cloud/log/__LOGBOOK_LINK__\n\nHappy sailing!\nThe PostgSail Team',
|
||||||
'New Logbook Entry',
|
'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 __LOGBOOK_LINK__\n\nHappy sailing!\nThe Saillogger 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 https://beta.openplotter.cloud/log/__LOGBOOK_LINK__\n\nHappy sailing!\nThe PostgSail Team'),
|
||||||
('user',
|
('user',
|
||||||
'Welcome',
|
'Welcome',
|
||||||
E'Hello __RECIPIENT__,\nCongratulations!\nYou successfully created an account.\nKeep in mind to register your vessel.\nHappy sailing!',
|
E'Hello __RECIPIENT__,\nCongratulations!\nYou successfully created an account.\nKeep in mind to register your vessel.\nHappy sailing!',
|
||||||
@@ -100,19 +100,19 @@ INSERT INTO email_templates VALUES
|
|||||||
E'Hi!\nHow are you?\n__BOAT__ is now linked to your account.'),
|
E'Hi!\nHow are you?\n__BOAT__ is now linked to your account.'),
|
||||||
('monitor_offline',
|
('monitor_offline',
|
||||||
'Offline',
|
'Offline',
|
||||||
E'__BOAT__ has been offline for more than an hour\r\nFind more details at https://openplotter.cloud/boats/\n',
|
E'__BOAT__ has been offline for more than an hour\r\nFind more details at https://beta.openplotter.cloud/boats/\n',
|
||||||
'Offline',
|
'Offline',
|
||||||
E'__BOAT__ has been offline for more than an hour\r\nFind more details at https://openplotter.cloud/boats/\n'),
|
E'__BOAT__ has been offline for more than an hour\r\nFind more details at https://beta.openplotter.cloud/boats/\n'),
|
||||||
('monitor_online',
|
('monitor_online',
|
||||||
'Online',
|
'Online',
|
||||||
E'__BOAT__ just came online\nFind more details at https://openplotter.cloud/boats/\n',
|
E'__BOAT__ just came online\nFind more details at https://beta.openplotter.cloud/boats/\n',
|
||||||
'Online',
|
'Online',
|
||||||
E'__BOAT__ just came online\nFind more details at https://openplotter.cloud/boats/\n'),
|
E'__BOAT__ just came online\nFind more details at https://beta.openplotter.cloud/boats/\n'),
|
||||||
('badge',
|
('badge',
|
||||||
'New Badge!',
|
'New Badge!',
|
||||||
E'Hello __RECIPIENT__,\nCongratulations! You have just unlocked a new badge: __BADGE_NAME__\nSee more details at https://openplotter.cloud/badges\nHappy sailing!\nThe Saillogger Team',
|
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',
|
||||||
'New Badge!',
|
'New Badge!',
|
||||||
E'Congratulations!\nYou have just unlocked a new badge: __BADGE_NAME__\nSee more details at https://openplotter.cloud/badges\nHappy sailing!\nThe Saillogger Team');
|
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');
|
||||||
|
|
||||||
---------------------------------------------------------------------------
|
---------------------------------------------------------------------------
|
||||||
-- python send email
|
-- python send email
|
||||||
@@ -150,6 +150,8 @@ AS $send_email_py$
|
|||||||
return None
|
return None
|
||||||
if 'logbook_name' in _user and _user['logbook_name']:
|
if 'logbook_name' in _user and _user['logbook_name']:
|
||||||
email_content = email_content.replace('__LOGBOOK_NAME__', _user['logbook_name'])
|
email_content = email_content.replace('__LOGBOOK_NAME__', _user['logbook_name'])
|
||||||
|
if 'logbook_link' in _user and _user['logbook_link']:
|
||||||
|
email_content = email_content.replace('__LOGBOOK_LINK__', str(_user['logbook_link']))
|
||||||
if 'recipient' in _user and _user['recipient']:
|
if 'recipient' in _user and _user['recipient']:
|
||||||
email_content = email_content.replace('__RECIPIENT__', _user['recipient'])
|
email_content = email_content.replace('__RECIPIENT__', _user['recipient'])
|
||||||
if 'boat' in _user and _user['boat']:
|
if 'boat' in _user and _user['boat']:
|
||||||
@@ -235,6 +237,8 @@ AS $send_pushover_py$
|
|||||||
# Replace fields using input jsonb obj
|
# Replace fields using input jsonb obj
|
||||||
if 'logbook_name' in _user and _user['logbook_name']:
|
if 'logbook_name' in _user and _user['logbook_name']:
|
||||||
pushover_message = pushover_message.replace('__LOGBOOK_NAME__', _user['logbook_name'])
|
pushover_message = pushover_message.replace('__LOGBOOK_NAME__', _user['logbook_name'])
|
||||||
|
if 'logbook_link' in _user and _user['logbook_link']:
|
||||||
|
pushover_message = pushover_message.replace('__LOGBOOK_LINK__', str(_user['logbook_link']))
|
||||||
if 'recipient' in _user and _user['recipient']:
|
if 'recipient' in _user and _user['recipient']:
|
||||||
pushover_message = pushover_message.replace('__RECIPIENT__', _user['recipient'])
|
pushover_message = pushover_message.replace('__RECIPIENT__', _user['recipient'])
|
||||||
if 'boat' in _user and _user['boat']:
|
if 'boat' in _user and _user['boat']:
|
||||||
@@ -338,6 +342,57 @@ COMMENT ON FUNCTION
|
|||||||
public.logbook_update_geom_distance_fn
|
public.logbook_update_geom_distance_fn
|
||||||
IS 'Update logbook details with geometry data an distance, ST_Length';
|
IS 'Update logbook details with geometry data an distance, ST_Length';
|
||||||
|
|
||||||
|
-- Create GeoJSON for api consum.
|
||||||
|
CREATE FUNCTION logbook_update_geojson_fn(IN _id integer, IN _start text, IN _end text,
|
||||||
|
OUT _track_geojson JSON
|
||||||
|
) AS $logbook_geojson$
|
||||||
|
declare
|
||||||
|
log_geojson jsonb;
|
||||||
|
metrics_geojson jsonb;
|
||||||
|
_map jsonb;
|
||||||
|
begin
|
||||||
|
-- GeoJson Feature Logbook linestring
|
||||||
|
SELECT
|
||||||
|
ST_AsGeoJSON(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 >= _start::TIMESTAMP WITHOUT TIME ZONE
|
||||||
|
AND time <= _end::TIMESTAMP WITHOUT TIME ZONE
|
||||||
|
ORDER BY m.time asc
|
||||||
|
)
|
||||||
|
) AS t;
|
||||||
|
|
||||||
|
--
|
||||||
|
select log_geojson::jsonb || metrics_geojson::jsonb into _map;
|
||||||
|
|
||||||
|
SELECT
|
||||||
|
json_build_object(
|
||||||
|
'type', 'FeatureCollection',
|
||||||
|
'features', _map
|
||||||
|
) into _track_geojson;
|
||||||
|
END;
|
||||||
|
$logbook_geojson$ LANGUAGE plpgsql;
|
||||||
|
-- Description
|
||||||
|
COMMENT ON FUNCTION
|
||||||
|
public.logbook_update_geojson_fn
|
||||||
|
IS 'Update logbook details with geojson';
|
||||||
|
|
||||||
|
|
||||||
-- Update pending new logbook from process queue
|
-- Update pending new logbook from process queue
|
||||||
DROP FUNCTION IF EXISTS process_logbook_queue_fn;
|
DROP FUNCTION IF EXISTS process_logbook_queue_fn;
|
||||||
CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void AS $process_logbook_queue$
|
CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void AS $process_logbook_queue$
|
||||||
@@ -350,8 +405,12 @@ CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void
|
|||||||
geo_rec record;
|
geo_rec record;
|
||||||
user_settings jsonb;
|
user_settings jsonb;
|
||||||
app_settings jsonb;
|
app_settings jsonb;
|
||||||
|
geojson jsonb;
|
||||||
BEGIN
|
BEGIN
|
||||||
-- If _id is not NULL
|
-- If _id is not NULL
|
||||||
|
IF _id IS NULL OR _id < 1 THEN
|
||||||
|
RAISE WARNING '-> process_logbook_queue_fn invalid input %', _id;
|
||||||
|
END IF;
|
||||||
SELECT * INTO logbook_rec
|
SELECT * INTO logbook_rec
|
||||||
FROM api.logbook
|
FROM api.logbook
|
||||||
WHERE active IS false
|
WHERE active IS false
|
||||||
@@ -368,10 +427,11 @@ CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void
|
|||||||
-- Update logbook entry with the latest metric data and calculate data
|
-- Update logbook entry with the latest metric data and calculate data
|
||||||
avg_rec := logbook_update_avg_fn(logbook_rec.id, logbook_rec._from_time::TEXT, logbook_rec._to_time::TEXT);
|
avg_rec := logbook_update_avg_fn(logbook_rec.id, logbook_rec._from_time::TEXT, logbook_rec._to_time::TEXT);
|
||||||
geo_rec := logbook_update_geom_distance_fn(logbook_rec.id, logbook_rec._from_time::TEXT, logbook_rec._to_time::TEXT);
|
geo_rec := logbook_update_geom_distance_fn(logbook_rec.id, logbook_rec._from_time::TEXT, logbook_rec._to_time::TEXT);
|
||||||
|
--geojson := logbook_update_geojson_fn(logbook_rec.id, logbook_rec._from_time::TEXT, logbook_rec._to_time::TEXT);
|
||||||
-- todo check on time start vs end
|
-- todo check on time start vs end
|
||||||
RAISE NOTICE 'Updating logbook entry [%] [%] [%]', logbook_rec.id, logbook_rec._from_time, logbook_rec._to_time;
|
RAISE NOTICE 'Updating logbook entry [%] [%] [%]', logbook_rec.id, logbook_rec._from_time, logbook_rec._to_time;
|
||||||
UPDATE api.logbook
|
UPDATE api.logbook
|
||||||
SET
|
SET
|
||||||
duration = (logbook_rec._to_time::timestamp without time zone - logbook_rec._from_time::timestamp without time zone),
|
duration = (logbook_rec._to_time::timestamp without time zone - logbook_rec._from_time::timestamp without time zone),
|
||||||
avg_speed = avg_rec.avg_speed,
|
avg_speed = avg_rec.avg_speed,
|
||||||
max_speed = avg_rec.max_speed,
|
max_speed = avg_rec.max_speed,
|
||||||
@@ -382,6 +442,13 @@ CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void
|
|||||||
track_geom = geo_rec._track_geom,
|
track_geom = geo_rec._track_geom,
|
||||||
distance = geo_rec._track_distance
|
distance = geo_rec._track_distance
|
||||||
WHERE id = logbook_rec.id;
|
WHERE id = logbook_rec.id;
|
||||||
|
|
||||||
|
-- GeoJSON
|
||||||
|
geojson := logbook_update_geojson_fn(logbook_rec.id, logbook_rec._from_time::TEXT, logbook_rec._to_time::TEXT);
|
||||||
|
UPDATE api.logbook
|
||||||
|
SET
|
||||||
|
track_geojson = geojson
|
||||||
|
WHERE id = logbook_rec.id;
|
||||||
-- Gather email and pushover app settings
|
-- Gather email and pushover app settings
|
||||||
app_settings := get_app_settings_fn();
|
app_settings := get_app_settings_fn();
|
||||||
-- Gather user settings
|
-- Gather user settings
|
||||||
@@ -407,9 +474,10 @@ CREATE OR REPLACE FUNCTION process_stay_queue_fn(IN _id integer) RETURNS void AS
|
|||||||
_name varchar;
|
_name varchar;
|
||||||
BEGIN
|
BEGIN
|
||||||
RAISE WARNING 'process_stay_queue_fn';
|
RAISE WARNING 'process_stay_queue_fn';
|
||||||
RAISE WARNING 'jwt %', current_setting('request.jwt.claims', true);
|
|
||||||
RAISE WARNING 'cur_user %', current_user;
|
|
||||||
-- If _id is not NULL
|
-- If _id is not NULL
|
||||||
|
IF _id IS NULL OR _id < 1 THEN
|
||||||
|
RAISE WARNING '-> process_stay_queue_fn invalid input %', _id;
|
||||||
|
END IF;
|
||||||
SELECT * INTO stay_rec
|
SELECT * INTO stay_rec
|
||||||
FROM api.stays
|
FROM api.stays
|
||||||
WHERE id = _id;
|
WHERE id = _id;
|
||||||
@@ -443,6 +511,9 @@ CREATE OR REPLACE FUNCTION process_moorage_queue_fn(IN _id integer) RETURNS void
|
|||||||
moorage_rec record;
|
moorage_rec record;
|
||||||
BEGIN
|
BEGIN
|
||||||
-- If _id is not NULL
|
-- If _id is not NULL
|
||||||
|
IF _id IS NULL OR _id < 1 THEN
|
||||||
|
RAISE WARNING '-> process_moorage_queue_fn invalid input %', _id;
|
||||||
|
END IF;
|
||||||
SELECT * INTO stay_rec
|
SELECT * INTO stay_rec
|
||||||
FROM api.stays
|
FROM api.stays
|
||||||
WHERE active IS false
|
WHERE active IS false
|
||||||
@@ -602,7 +673,8 @@ AS $get_user_settings_from_log$
|
|||||||
'boat' , v.name,
|
'boat' , v.name,
|
||||||
'recipient', a.first,
|
'recipient', a.first,
|
||||||
'email', v.owner_email,
|
'email', v.owner_email,
|
||||||
'logbook_name', l.name) INTO user_settings
|
'logbook_name', l.name,
|
||||||
|
'logbook_link', l.id) INTO user_settings
|
||||||
FROM auth.accounts a, auth.vessels v, api.metadata m, api.logbook l
|
FROM auth.accounts a, auth.vessels v, api.metadata m, api.logbook l
|
||||||
WHERE lower(a.email) = lower(v.owner_email)
|
WHERE lower(a.email) = lower(v.owner_email)
|
||||||
-- AND lower(v.name) = lower(m.name)
|
-- AND lower(v.name) = lower(m.name)
|
||||||
@@ -869,6 +941,23 @@ BEGIN
|
|||||||
RAISE EXCEPTION 'Invalid user'
|
RAISE EXCEPTION 'Invalid user'
|
||||||
USING HINT = 'Unkown user';
|
USING HINT = 'Unkown user';
|
||||||
END IF;
|
END IF;
|
||||||
|
-- Check a vessel and user exist
|
||||||
|
SELECT * INTO vessel_rec
|
||||||
|
FROM auth.vessels, auth.accounts
|
||||||
|
WHERE auth.vessels.owner_email = _email
|
||||||
|
AND auth.accounts.email = _email;
|
||||||
|
-- check if boat exist yet?
|
||||||
|
IF vessel_rec.owner_email IS NULL THEN
|
||||||
|
RETURN; -- ignore if not exist
|
||||||
|
END IF;
|
||||||
|
IF vessel_rec.mmsi IS NULL THEN
|
||||||
|
RAISE EXCEPTION 'Invalid vessel'
|
||||||
|
USING HINT = 'Unkown vessel mmsi';
|
||||||
|
END IF;
|
||||||
|
PERFORM set_config('vessel.mmsi', vessel_rec.mmsi, false);
|
||||||
|
PERFORM set_config('vessel.name', vessel_rec.name, false);
|
||||||
|
RAISE WARNING 'public.check_jwt() user_role vessel.mmsi %', current_setting('vessel.mmsi', false);
|
||||||
|
RAISE WARNING 'public.check_jwt() user_role vessel.name %', current_setting('vessel.name', false);
|
||||||
ELSIF _role = 'vessel_role' THEN
|
ELSIF _role = 'vessel_role' THEN
|
||||||
-- Check the vessel and user exist
|
-- Check the vessel and user exist
|
||||||
SELECT * INTO vessel_rec
|
SELECT * INTO vessel_rec
|
||||||
@@ -885,7 +974,8 @@ BEGIN
|
|||||||
USING HINT = 'Unkown vessel mmsi';
|
USING HINT = 'Unkown vessel mmsi';
|
||||||
END IF;
|
END IF;
|
||||||
PERFORM set_config('vessel.mmsi', vessel_rec.mmsi, false);
|
PERFORM set_config('vessel.mmsi', vessel_rec.mmsi, false);
|
||||||
RAISE WARNING 'vessel.mmsi %', current_setting('vessel.mmsi', false);
|
--RAISE WARNING 'vessel.mmsi %', current_setting('vessel.mmsi', false);
|
||||||
|
PERFORM set_config('vessel.name', vessel_rec.name, false);
|
||||||
ELSIF _role <> 'api_anonymous' THEN
|
ELSIF _role <> 'api_anonymous' THEN
|
||||||
RAISE EXCEPTION 'Invalid role'
|
RAISE EXCEPTION 'Invalid role'
|
||||||
USING HINT = 'Stop being so evil and maybe you can log in';
|
USING HINT = 'Stop being so evil and maybe you can log in';
|
||||||
@@ -899,12 +989,12 @@ $$ language plpgsql security definer;
|
|||||||
CREATE OR REPLACE FUNCTION api.run_cron_jobs() RETURNS void AS $$
|
CREATE OR REPLACE FUNCTION api.run_cron_jobs() RETURNS void AS $$
|
||||||
BEGIN
|
BEGIN
|
||||||
-- In correct order
|
-- In correct order
|
||||||
perform public.cron_process_new_account_fn();
|
select public.cron_process_new_account_fn();
|
||||||
perform public.cron_process_new_vessel_fn();
|
select public.cron_process_new_vessel_fn();
|
||||||
perform public.cron_process_monitor_online_fn();
|
select public.cron_process_monitor_online_fn();
|
||||||
perform public.cron_process_new_logbook_fn();
|
select public.cron_process_new_logbook_fn();
|
||||||
perform public.cron_process_new_stay_fn();
|
select public.cron_process_new_stay_fn();
|
||||||
perform public.cron_process_new_moorage_fn();
|
select public.cron_process_new_moorage_fn();
|
||||||
perform public.cron_process_monitor_offline_fn();
|
select public.cron_process_monitor_offline_fn();
|
||||||
END
|
END
|
||||||
$$ language plpgsql security definer;
|
$$ language plpgsql security definer;
|
@@ -189,7 +189,7 @@ begin
|
|||||||
-- check vessel exist
|
-- check vessel exist
|
||||||
SELECT * INTO vessel_rec
|
SELECT * INTO vessel_rec
|
||||||
FROM auth.vessels vessel
|
FROM auth.vessels vessel
|
||||||
WHERE vessel.owner_email = vessel_email
|
WHERE LOWER(vessel.owner_email) = LOWER(vessel_email)
|
||||||
AND vessel.mmsi = vessel_mmsi
|
AND vessel.mmsi = vessel_mmsi
|
||||||
AND LOWER(vessel.name) = LOWER(vessel_name);
|
AND LOWER(vessel.name) = LOWER(vessel_name);
|
||||||
if vessel_rec is null then
|
if vessel_rec is null then
|
||||||
|
@@ -17,7 +17,9 @@ select current_database();
|
|||||||
-- nologin
|
-- 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.
|
||||||
-- api_anonymous allows JWT token generation with an expiration time via function api.login() from auth.accounts table
|
-- api_anonymous allows JWT token generation with an expiration time via function api.login() from auth.accounts table
|
||||||
create role api_anonymous nologin noinherit;
|
create role api_anonymous WITH NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOLOGIN NOBYPASSRLS NOREPLICATION CONNECTION LIMIT 10;
|
||||||
|
-- Limit to 10 connections
|
||||||
|
--alter user api_anonymous connection limit 10;
|
||||||
grant usage on schema api to api_anonymous;
|
grant usage on schema api to api_anonymous;
|
||||||
-- explicitly limit EXECUTE privileges to only signup and login functions
|
-- explicitly limit EXECUTE privileges to only signup and login functions
|
||||||
grant execute on function api.login(text,text) to api_anonymous;
|
grant execute on function api.login(text,text) to api_anonymous;
|
||||||
@@ -27,35 +29,103 @@ grant execute on function public.check_jwt() to api_anonymous;
|
|||||||
|
|
||||||
-- authenticator
|
-- authenticator
|
||||||
-- login role
|
-- login role
|
||||||
create role authenticator noinherit login password 'mysecretpassword';
|
create role authenticator NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT login password 'mysecretpassword';
|
||||||
grant api_anonymous to authenticator;
|
grant api_anonymous to authenticator;
|
||||||
|
|
||||||
-- Grafana user and role with login, read-only
|
-- Grafana user and role with login, read-only, limit 10 connections
|
||||||
CREATE ROLE grafana WITH LOGIN PASSWORD 'mysecretpassword';
|
CREATE ROLE grafana WITH NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOBYPASSRLS NOREPLICATION CONNECTION LIMIT 10 LOGIN PASSWORD 'mysecretpassword';
|
||||||
GRANT USAGE ON SCHEMA api TO grafana;
|
GRANT USAGE ON SCHEMA api TO grafana;
|
||||||
GRANT USAGE, SELECT ON SEQUENCE api.logbook_id_seq,api.metadata_id_seq,api.moorages_id_seq,api.stays_id_seq TO grafana;
|
GRANT USAGE, SELECT ON SEQUENCE api.logbook_id_seq,api.metadata_id_seq,api.moorages_id_seq,api.stays_id_seq TO grafana;
|
||||||
GRANT SELECT ON TABLE api.metrics,api.logbook,api.moorages,api.stays,api.metadata TO grafana;
|
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;
|
||||||
|
|
||||||
-- User:
|
-- User:
|
||||||
-- nologin
|
-- nologin
|
||||||
-- read-only for all and Read-Write on logbook, stays and moorage except for name COLUMN ?
|
-- read-only for all and Read-Write on logbook, stays and moorage except for specific (name, notes) COLUMNS ?
|
||||||
CREATE ROLE user_role WITH NOLOGIN;
|
CREATE ROLE user_role WITH NOLOGIN NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOBYPASSRLS NOREPLICATION;
|
||||||
GRANT user_role to authenticator;
|
GRANT user_role to authenticator;
|
||||||
GRANT USAGE ON SCHEMA api TO user_role;
|
GRANT USAGE ON SCHEMA api TO user_role;
|
||||||
GRANT USAGE, SELECT ON SEQUENCE api.logbook_id_seq,api.metadata_id_seq,api.moorages_id_seq,api.stays_id_seq TO user_role;
|
GRANT USAGE, SELECT ON SEQUENCE api.logbook_id_seq,api.metadata_id_seq,api.moorages_id_seq,api.stays_id_seq TO user_role;
|
||||||
GRANT SELECT ON TABLE api.metrics,api.logbook,api.moorages,api.stays,api.metadata TO user_role;
|
GRANT SELECT ON TABLE api.metrics,api.logbook,api.moorages,api.stays,api.metadata,api.stays_at TO user_role;
|
||||||
|
GRANT SELECT ON TABLE auth.vessels TO user_role;
|
||||||
-- Allow update on table for notes
|
-- Allow update on table for notes
|
||||||
GRANT UPDATE ON TABLE api.logbook,api.moorages,api.stays TO user_role;
|
--GRANT UPDATE ON TABLE api.logbook,api.moorages,api.stays TO user_role;
|
||||||
|
-- Allow users to update certain columns
|
||||||
|
GRANT UPDATE (name, notes) ON api.logbook TO user_role;
|
||||||
|
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;
|
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA api TO user_role;
|
||||||
-- explicitly limit EXECUTE privileges to pgrest db-pre-request function
|
-- explicitly limit EXECUTE privileges to pgrest db-pre-request function
|
||||||
GRANT EXECUTE ON FUNCTION public.check_jwt() 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;
|
||||||
|
|
||||||
|
-- Update ownership for security user_role as run by web user.
|
||||||
|
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
|
||||||
|
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;
|
||||||
|
|
||||||
|
-- For cron job
|
||||||
|
GRANT EXECUTE ON function api.run_cron_jobs() TO 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
|
-- Allow read on VIEWS
|
||||||
GRANT SELECT ON TABLE api.logs_view,api.moorages_view,api.stays_view TO user_role;
|
--GRANT SELECT ON TABLE api.logs_view,api.moorages_view,api.stays_view,api.vessel_view TO user_role;
|
||||||
|
|
||||||
-- Vessel:
|
-- Vessel:
|
||||||
-- nologin
|
-- nologin
|
||||||
-- insert-update-only for api.metrics,api.logbook,api.moorages,api.stays,api.metadata and sequences and process_queue
|
-- insert-update-only for api.metrics,api.logbook,api.moorages,api.stays,api.metadata and sequences and process_queue
|
||||||
CREATE ROLE vessel_role WITH NOLOGIN;
|
CREATE ROLE vessel_role WITH NOLOGIN NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOBYPASSRLS NOREPLICATION;
|
||||||
GRANT vessel_role to authenticator;
|
GRANT vessel_role to authenticator;
|
||||||
GRANT USAGE ON SCHEMA api TO vessel_role;
|
GRANT USAGE ON SCHEMA api TO vessel_role;
|
||||||
GRANT INSERT, UPDATE, SELECT ON TABLE api.metrics,api.logbook,api.moorages,api.stays,api.metadata TO vessel_role;
|
GRANT INSERT, UPDATE, SELECT ON TABLE api.metrics,api.logbook,api.moorages,api.stays,api.metadata TO vessel_role;
|
||||||
@@ -154,3 +224,18 @@ CREATE POLICY api_vessel_role ON api.moorages TO vessel_role
|
|||||||
CREATE POLICY api_user_role ON api.moorages TO user_role
|
CREATE POLICY api_user_role ON api.moorages TO user_role
|
||||||
USING (client_id LIKE '%' || current_setting('vessel.mmsi', false) || '%')
|
USING (client_id LIKE '%' || current_setting('vessel.mmsi', false) || '%')
|
||||||
WITH CHECK (client_id LIKE '%' || current_setting('vessel.mmsi', false) || '%');
|
WITH CHECK (client_id LIKE '%' || current_setting('vessel.mmsi', false) || '%');
|
||||||
|
|
||||||
|
-- Be sure to enable row level security on the table
|
||||||
|
ALTER TABLE auth.vessels ENABLE ROW LEVEL SECURITY;
|
||||||
|
-- Administrator can see all rows and add any rows
|
||||||
|
CREATE POLICY admin_all ON auth.vessels TO current_user
|
||||||
|
USING (true)
|
||||||
|
WITH CHECK (true);
|
||||||
|
-- Allow user_role to update and select on their own records
|
||||||
|
CREATE POLICY api_user_role ON auth.vessels TO user_role
|
||||||
|
USING (mmsi = current_setting('vessel.mmsi', false)
|
||||||
|
AND owner_email = current_setting('request.jwt.claims', false)::json->>'email'
|
||||||
|
)
|
||||||
|
WITH CHECK (mmsi = current_setting('vessel.mmsi', false)
|
||||||
|
AND owner_email = current_setting('request.jwt.claims', false)::json->>'email'
|
||||||
|
)
|
||||||
|
@@ -1 +1 @@
|
|||||||
0.0.4
|
0.0.5
|
||||||
|
Reference in New Issue
Block a user