mirror of
https://github.com/xbgmsharp/postgsail.git
synced 2025-09-18 03:37:47 +00:00
Compare commits
11 Commits
Author | SHA1 | Date | |
---|---|---|---|
![]() |
9e8009a764 | ||
![]() |
dca77c3293 | ||
![]() |
8af527f574 | ||
![]() |
0f399293eb | ||
![]() |
57dfaf2158 | ||
![]() |
3a2e091744 | ||
![]() |
7c5bd21e80 | ||
![]() |
33af7bec1b | ||
![]() |
023ad56926 | ||
![]() |
91cf679876 | ||
![]() |
1b81900036 |
@@ -1,8 +1,8 @@
|
|||||||
# PostgSail
|
# 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
|
### 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
|
### Features
|
||||||
- Automatically log your voyages without manually starting or stopping a trip.
|
- 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.
|
- Monitor your boat (position, depth, wind, temperature, battery charge status, etc.) remotely.
|
||||||
- History: view trends.
|
- History: view trends.
|
||||||
- Alert monitoring: get notification on low voltage or low fuel remotely.
|
- Alert monitoring: get notification on low voltage or low fuel remotely.
|
||||||
- Notification via email or PushOver.
|
- Notification via email or PushOver, Telegram
|
||||||
|
|
||||||
### Cloud
|
### Cloud
|
||||||
The cloud advantage.
|
The cloud advantage.
|
||||||
|
@@ -469,10 +469,13 @@ COMMENT ON TRIGGER
|
|||||||
metrics_trigger ON api.metrics
|
metrics_trigger ON api.metrics
|
||||||
IS 'BEFORE INSERT ON api.metrics run function metrics_trigger_fn';
|
IS 'BEFORE INSERT ON api.metrics run function metrics_trigger_fn';
|
||||||
|
|
||||||
|
---------------------------------------------------------------------------
|
||||||
|
-- API helper functions
|
||||||
|
--
|
||||||
|
---------------------------------------------------------------------------
|
||||||
|
|
||||||
---------------------------------------------------------------------------
|
---------------------------------------------------------------------------
|
||||||
-- Functions API schema
|
-- Functions API schema
|
||||||
|
|
||||||
-- Export a log entry to geojson
|
-- Export a log entry to geojson
|
||||||
DROP FUNCTION IF EXISTS api.export_logbook_geojson_point_fn;
|
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$
|
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;
|
geojson json;
|
||||||
BEGIN
|
BEGIN
|
||||||
-- If _id is is not NULL and > 0
|
-- 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
|
FROM api.logbook l
|
||||||
WHERE l.id = _id;
|
WHERE l.id = _id;
|
||||||
RETURN geojson;
|
RETURN geojson;
|
||||||
@@ -539,6 +542,110 @@ COMMENT ON FUNCTION
|
|||||||
api.export_logbook_geojson_linestring_fn
|
api.export_logbook_geojson_linestring_fn
|
||||||
IS 'Export a log entry to geojson feature linestring';
|
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
|
-- Find all log from and to moorage geopoint within 100m
|
||||||
DROP FUNCTION IF EXISTS api.find_log_from_moorage_fn;
|
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$
|
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
|
api.find_stay_from_moorage_fn
|
||||||
IS 'Find all stay within 100m of moorage geopoint';
|
IS 'Find all stay within 100m of moorage geopoint';
|
||||||
|
|
||||||
|
---------------------------------------------------------------------------
|
||||||
|
-- API helper view
|
||||||
|
--
|
||||||
|
---------------------------------------------------------------------------
|
||||||
|
|
||||||
---------------------------------------------------------------------------
|
---------------------------------------------------------------------------
|
||||||
-- Views
|
-- Views
|
||||||
-- Views are invoked with the privileges of the view owner,
|
-- Views are invoked with the privileges of the view owner,
|
||||||
-- make the user_role the view’s owner.
|
-- make the user_role the view’s owner.
|
||||||
--
|
---------------------------------------------------------------------------
|
||||||
|
|
||||||
CREATE VIEW first_metric AS
|
CREATE VIEW first_metric AS
|
||||||
SELECT *
|
SELECT *
|
||||||
FROM api.metrics
|
FROM api.metrics
|
||||||
@@ -874,107 +987,3 @@ CREATE VIEW api.voltage AS
|
|||||||
cast(metrics-> 'electrical.batteries.victronDevice.voltage' AS numeric) AS victronDeviceVoltage
|
cast(metrics-> 'electrical.batteries.victronDevice.voltage' AS numeric) AS victronDeviceVoltage
|
||||||
FROM api.metrics m
|
FROM api.metrics m
|
||||||
ORDER BY time DESC LIMIT 1;
|
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';
|
|
||||||
|
@@ -377,9 +377,9 @@ CREATE FUNCTION logbook_update_geojson_fn(IN _id integer, IN _start text, IN _en
|
|||||||
)
|
)
|
||||||
) AS t;
|
) AS t;
|
||||||
|
|
||||||
--
|
-- Merge jsonb
|
||||||
select log_geojson::jsonb || metrics_geojson::jsonb into _map;
|
select log_geojson::jsonb || metrics_geojson::jsonb into _map;
|
||||||
|
-- output
|
||||||
SELECT
|
SELECT
|
||||||
json_build_object(
|
json_build_object(
|
||||||
'type', 'FeatureCollection',
|
'type', 'FeatureCollection',
|
||||||
@@ -390,7 +390,7 @@ $logbook_geojson$ LANGUAGE plpgsql;
|
|||||||
-- Description
|
-- Description
|
||||||
COMMENT ON FUNCTION
|
COMMENT ON FUNCTION
|
||||||
public.logbook_update_geojson_fn
|
public.logbook_update_geojson_fn
|
||||||
IS 'Update logbook details with geojson';
|
IS 'Update log details with geojson';
|
||||||
|
|
||||||
|
|
||||||
-- Update pending new logbook from process queue
|
-- Update pending new logbook from process queue
|
||||||
@@ -473,7 +473,7 @@ CREATE OR REPLACE FUNCTION process_stay_queue_fn(IN _id integer) RETURNS void AS
|
|||||||
stay_rec record;
|
stay_rec record;
|
||||||
_name varchar;
|
_name varchar;
|
||||||
BEGIN
|
BEGIN
|
||||||
RAISE WARNING 'process_stay_queue_fn';
|
RAISE NOTICE 'process_stay_queue_fn';
|
||||||
-- If _id is not NULL
|
-- If _id is not NULL
|
||||||
IF _id IS NULL OR _id < 1 THEN
|
IF _id IS NULL OR _id < 1 THEN
|
||||||
RAISE WARNING '-> process_stay_queue_fn invalid input %', _id;
|
RAISE WARNING '-> process_stay_queue_fn invalid input %', _id;
|
||||||
@@ -510,6 +510,7 @@ CREATE OR REPLACE FUNCTION process_moorage_queue_fn(IN _id integer) RETURNS void
|
|||||||
stay_rec record;
|
stay_rec record;
|
||||||
moorage_rec record;
|
moorage_rec record;
|
||||||
BEGIN
|
BEGIN
|
||||||
|
RAISE NOTICE 'process_moorage_queue_fn';
|
||||||
-- If _id is not NULL
|
-- If _id is not NULL
|
||||||
IF _id IS NULL OR _id < 1 THEN
|
IF _id IS NULL OR _id < 1 THEN
|
||||||
RAISE WARNING '-> process_moorage_queue_fn invalid input %', _id;
|
RAISE WARNING '-> process_moorage_queue_fn invalid input %', _id;
|
||||||
@@ -676,8 +677,8 @@ AS $get_user_settings_from_log$
|
|||||||
'logbook_name', l.name,
|
'logbook_name', l.name,
|
||||||
'logbook_link', l.id) INTO user_settings
|
'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)
|
||||||
AND m.client_id = l.client_id
|
AND m.client_id = l.client_id
|
||||||
AND l.client_id = logbook_rec.client_id
|
AND l.client_id = logbook_rec.client_id
|
||||||
AND l.id = logbook_rec.id;
|
AND l.id = logbook_rec.id;
|
||||||
@@ -763,8 +764,8 @@ AS $get_user_settings_from_clientid$
|
|||||||
'badges', a.preferences->'badges',
|
'badges', a.preferences->'badges',
|
||||||
'logbook_name', logbook_name ) INTO user_settings
|
'logbook_name', logbook_name ) INTO user_settings
|
||||||
FROM auth.accounts a, auth.vessels v, api.metadata m
|
FROM auth.accounts a, auth.vessels v, api.metadata m
|
||||||
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)
|
||||||
AND m.mmsi = v.mmsi
|
AND m.mmsi = v.mmsi
|
||||||
AND m.client_id = clientid;
|
AND m.client_id = clientid;
|
||||||
END;
|
END;
|
||||||
@@ -923,6 +924,7 @@ DECLARE
|
|||||||
_role name;
|
_role name;
|
||||||
_email name;
|
_email name;
|
||||||
_mmsi name;
|
_mmsi name;
|
||||||
|
_path name;
|
||||||
account_rec record;
|
account_rec record;
|
||||||
vessel_rec record;
|
vessel_rec record;
|
||||||
BEGIN
|
BEGIN
|
||||||
@@ -939,7 +941,16 @@ BEGIN
|
|||||||
WHERE auth.accounts.email = _email;
|
WHERE auth.accounts.email = _email;
|
||||||
IF account_rec.email IS NULL THEN
|
IF account_rec.email IS NULL THEN
|
||||||
RAISE EXCEPTION 'Invalid user'
|
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;
|
END IF;
|
||||||
-- Check a vessel and user exist
|
-- Check a vessel and user exist
|
||||||
SELECT * INTO vessel_rec
|
SELECT * INTO vessel_rec
|
||||||
@@ -948,7 +959,12 @@ BEGIN
|
|||||||
AND auth.accounts.email = _email;
|
AND auth.accounts.email = _email;
|
||||||
-- check if boat exist yet?
|
-- check if boat exist yet?
|
||||||
IF vessel_rec.owner_email IS NULL THEN
|
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;
|
END IF;
|
||||||
IF vessel_rec.mmsi IS NULL THEN
|
IF vessel_rec.mmsi IS NULL THEN
|
||||||
RAISE EXCEPTION 'Invalid vessel'
|
RAISE EXCEPTION 'Invalid vessel'
|
||||||
|
129
initdb/02_5_signalk_api_deps.sql
Normal file
129
initdb/02_5_signalk_api_deps.sql
Normal file
@@ -0,0 +1,129 @@
|
|||||||
|
---------------------------------------------------------------------------
|
||||||
|
-- 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
|
||||||
|
)
|
||||||
|
) AS t
|
||||||
|
) AS geojson_t
|
||||||
|
WHERE v.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
|
-- api_anonymous
|
||||||
-- 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, limit 10 connections
|
||||||
-- 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 WITH NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOLOGIN NOBYPASSRLS NOREPLICATION CONNECTION LIMIT 10;
|
create role api_anonymous WITH NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOLOGIN NOBYPASSRLS NOREPLICATION CONNECTION LIMIT 10;
|
||||||
-- Limit to 10 connections
|
-- 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;
|
GRANT SELECT ON TABLE api.metrics,api.logbook,api.moorages,api.stays,api.metadata TO grafana;
|
||||||
-- Allow read on VIEWS
|
-- 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 TO grafana;
|
||||||
|
--GRANT SELECT ON TABLE api.logs_view,api.moorages_view,api.stays_view,api.vessel_view TO grafana;
|
||||||
|
|
||||||
-- User:
|
-- User:
|
||||||
-- nologin
|
-- nologin, web api only
|
||||||
-- read-only for all and Read-Write on logbook, stays and moorage except for specific (name, notes) COLUMNS ?
|
-- 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;
|
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;
|
||||||
@@ -57,70 +58,32 @@ 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 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 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.check_jwt() TO user_role;
|
||||||
GRANT EXECUTE ON FUNCTION public.st_asgeojson(text) 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;
|
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.
|
-- 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.stays_view OWNER TO user_role;
|
||||||
ALTER VIEW api.moorages_view OWNER TO user_role;
|
ALTER VIEW api.moorages_view OWNER TO user_role;
|
||||||
ALTER VIEW api.logs_view OWNER TO user_role;
|
ALTER VIEW api.logs_view OWNER TO user_role;
|
||||||
-- Remove all right except select
|
-- 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.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.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.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
|
-- Allow read and update on VIEWS
|
||||||
ALTER VIEW api.logs_view OWNER TO user_role;
|
-- Web detail view
|
||||||
REVOKE TRUNCATE, DELETE, TRIGGER, INSERT ON TABLE api.stays_view FROM user_role;
|
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
|
ALTER VIEW api.vessels_view OWNER TO user_role;
|
||||||
GRANT EXECUTE ON function api.run_cron_jobs() TO user_role;
|
-- Remove all permissions except select and update
|
||||||
|
REVOKE TRUNCATE, DELETE, TRIGGER, INSERT ON TABLE api.vessels_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:
|
-- Vessel:
|
||||||
-- nologin
|
-- nologin
|
||||||
@@ -135,6 +98,7 @@ GRANT USAGE, SELECT ON SEQUENCE public.process_queue_id_seq TO vessel_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 vessel_role;
|
GRANT EXECUTE ON FUNCTION public.check_jwt() to vessel_role;
|
||||||
|
|
||||||
|
--- Scheduler:
|
||||||
-- TODO: currently cron function are run as super user, switch to scheduler role.
|
-- 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
|
-- Scheduler read-only all, and write on logbook, stays, moorage, process_queue
|
||||||
-- Crons
|
-- Crons
|
@@ -1 +1 @@
|
|||||||
0.0.5
|
0.0.7
|
||||||
|
Reference in New Issue
Block a user