5 Commits

Author SHA1 Message Date
xbgmsharp
7c5bd21e80 Release v0.0.6 2022-09-01 19:33:00 +02:00
xbgmsharp
33af7bec1b Update permissions files 2022-09-01 19:31:25 +02:00
xbgmsharp
023ad56926 Add more api endpoint with dependencies 2022-09-01 19:27:11 +02:00
xbgmsharp
91cf679876 Update comment 2022-09-01 19:25:50 +02:00
xbgmsharp
1b81900036 Update permissions for log details view 2022-09-01 19:25:27 +02:00
4 changed files with 97 additions and 32 deletions

View File

@@ -390,7 +390,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

View File

@@ -0,0 +1,79 @@
---------------------------------------------------------------------------
-- singalk db permissions
--
-- List current database
select current_database();
-- connect to the DB
\c signalk
-- List vessel
--TODO add geojson with position
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');
-- 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
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 first,last,preferences,created_at INTO settings
from auth.accounts
where lower(email) = lower(current_setting('request.jwt.claims', true)::json->>'email');
END;
$user_settings$ language plpgsql security definer;
-- Description
COMMENT ON FUNCTION
api.settings_fn
IS 'Expose user settings to API';

View File

@@ -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
@@ -41,8 +41,8 @@ GRANT SELECT ON TABLE api.metrics,api.logbook,api.moorages,api.stays,api.metadat
GRANT SELECT ON TABLE api.logs_view,api.moorages_view,api.stays_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,11 +57,15 @@ 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;
@@ -72,13 +76,15 @@ REVOKE UPDATE, TRUNCATE, REFERENCES, DELETE, TRIGGER, INSERT ON TABLE api.logs_v
--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;
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;
--GRANT EXECUTE ON function api.run_cron_jobs() TO user_role;
-- List vessel
--TODO add geojson with position
CREATE OR REPLACE VIEW api.vessel_view AS
SELECT
v.name as name,
@@ -94,30 +100,9 @@ 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, ...';
GRANT EXECUTE ON FUNCTION api.vessel_fn() TO user_role;
GRANT EXECUTE ON FUNCTION api.settings_fn() TO user_role;
-- Allow read on VIEWS
--GRANT SELECT ON TABLE api.logs_view,api.moorages_view,api.stays_view,api.vessel_view TO user_role;
@@ -135,6 +120,7 @@ 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

View File

@@ -1 +1 @@
0.0.5
0.0.6