Remove mmsi dependency, update to use vessel_id instead

This commit is contained in:
xbgmsharp
2022-12-05 23:19:58 +01:00
parent 0f59a31cdc
commit 5ce5b606e9
2 changed files with 29 additions and 20 deletions

View File

@@ -8,20 +8,29 @@ select current_database();
-- connect to the DB -- connect to the DB
\c signalk \c signalk
-- Link auth.vessels with api.metadata
ALTER TABLE api.metadata ADD vessel_id text NOT NULL REFERENCES auth.vessels(vessel_id) ON DELETE RESTRICT;
COMMENT ON COLUMN api.metadata.vessel_id IS 'Link auth.vessels with api.metadata';
-- List vessel -- List vessel
--TODO add geojson with position --TODO add geojson with position
DROP VIEW IF EXISTS api.vessels_view; DROP VIEW IF EXISTS api.vessels_view;
CREATE OR REPLACE VIEW api.vessels_view AS CREATE OR REPLACE VIEW api.vessels_view AS
WITH metadata AS (
SELECT COALESCE(
(SELECT m.time
FROM api.metadata m
WHERE m.vessel_id = current_setting('vessel.id')
)::TEXT ,
'Never'::TEXT ) as last_contact
)
SELECT SELECT
v.name as name, v.name as name,
v.mmsi as mmsi, v.mmsi as mmsi,
v.created_at as created_at, v.created_at as created_at,
coalesce(m.time, null) as last_contact m.last_contact as last_contact
FROM auth.vessels v, api.metadata m FROM auth.vessels v, metadata m
WHERE WHERE v.owner_email = current_setting('user.email');
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; DROP VIEW IF EXISTS api.vessel_p_view;
CREATE OR REPLACE VIEW api.vessel_p_view AS CREATE OR REPLACE VIEW api.vessel_p_view AS
@@ -31,7 +40,7 @@ CREATE OR REPLACE VIEW api.vessel_p_view AS
v.created_at as created_at, v.created_at as created_at,
null as last_contact null as last_contact
FROM auth.vessels v FROM auth.vessels v
WHERE lower(v.owner_email) = lower(current_setting('request.jwt.claims', true)::json->>'email'); WHERE v.owner_email = current_setting('user.email');
-- Or function? -- Or function?
-- TODO Improve: return null until the vessel has sent metadata? -- TODO Improve: return null until the vessel has sent metadata?
@@ -43,7 +52,7 @@ AS $vessel$
SELECT SELECT
json_build_object( json_build_object(
'name', v.name, 'name', v.name,
'mmsi', v.mmsi, 'mmsi', coalesce(v.mmsi, null),
'created_at', v.created_at, 'created_at', v.created_at,
'last_contact', coalesce(m.time, null), 'last_contact', coalesce(m.time, null),
'geojson', coalesce(ST_AsGeoJSON(geojson_t.*)::json, null) 'geojson', coalesce(ST_AsGeoJSON(geojson_t.*)::json, null)
@@ -69,8 +78,8 @@ AS $vessel$
) AS t ) AS t
) AS geojson_t ) AS geojson_t
WHERE WHERE
m.mmsi = current_setting('vessel.mmsi') m.vessel_id = current_setting('vessel.id')
AND m.mmsi = v.mmsi; AND m.vessel_id = v.vessel_id;
--RAISE notice 'api.vessel_fn %', obj; --RAISE notice 'api.vessel_fn %', obj;
END; END;
$vessel$ language plpgsql security definer; $vessel$ language plpgsql security definer;
@@ -89,7 +98,7 @@ AS $user_settings$
select email,first,last,preferences,created_at, select email,first,last,preferences,created_at,
INITCAP(CONCAT (LEFT(first, 1), ' ', last)) AS username INITCAP(CONCAT (LEFT(first, 1), ' ', last)) AS username
from auth.accounts from auth.accounts
where lower(email) = lower(current_setting('request.jwt.claims', true)::json->>'email') where email = current_setting('user.email')
) row; ) row;
END; END;
$user_settings$ language plpgsql security definer; $user_settings$ language plpgsql security definer;
@@ -186,7 +195,7 @@ BEGIN
SET preferences = SET preferences =
jsonb_set(preferences::jsonb, key::text[], _value::jsonb) jsonb_set(preferences::jsonb, key::text[], _value::jsonb)
WHERE WHERE
lower(email) = lower(current_setting('user.email', true)); email = current_setting('user.email', true);
IF FOUND THEN IF FOUND THEN
--RAISE WARNING '-> update_user_preferences_fn True'; --RAISE WARNING '-> update_user_preferences_fn True';
RETURN True; RETURN True;

View File

@@ -31,7 +31,7 @@ grant execute on function public.check_jwt() to api_anonymous;
-- explicitly limit EXECUTE privileges to only telegram bot auth function -- explicitly limit EXECUTE privileges to only telegram bot auth function
grant execute on function api.bot(text,bigint) to api_anonymous; grant execute on function api.bot(text,bigint) to api_anonymous;
-- explicitly limit EXECUTE privileges to only pushover subscription validation function -- explicitly limit EXECUTE privileges to only pushover subscription validation function
grant execute on function api.generate_otp_fn(text) to api_anonymous; grant execute on function api.email_fn(text) to api_anonymous;
grant execute on function api.pushover_fn(text,text) to api_anonymous; grant execute on function api.pushover_fn(text,text) to api_anonymous;
grant execute on function api.telegram_fn(text,text) to api_anonymous; grant execute on function api.telegram_fn(text,text) to api_anonymous;
@@ -136,7 +136,7 @@ GRANT EXECUTE ON FUNCTION public.check_jwt() to vessel_role;
--CREATE ROLE scheduler WITH NOLOGIN NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOBYPASSRLS NOREPLICATION; --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; CREATE ROLE scheduler WITH NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOBYPASSRLS NOREPLICATION CONNECTION LIMIT 10 LOGIN;
comment on role vessel_role is comment on role vessel_role is
'Role that pgcron will use to process notification logbook,moorages,stays,monitoring.'; 'Role that pgcron will use to process logbook,moorages,stays,monitoring and notification.';
GRANT scheduler to authenticator; GRANT scheduler to authenticator;
GRANT USAGE ON SCHEMA api TO scheduler; GRANT USAGE ON SCHEMA api TO scheduler;
GRANT SELECT ON TABLE api.metrics,api.metadata TO scheduler; GRANT SELECT ON TABLE api.metrics,api.metadata TO scheduler;
@@ -146,7 +146,7 @@ GRANT SELECT ON ALL TABLES IN SCHEMA public TO scheduler;
GRANT SELECT,UPDATE ON TABLE public.process_queue TO scheduler; GRANT SELECT,UPDATE ON TABLE public.process_queue TO scheduler;
GRANT USAGE ON SCHEMA auth TO scheduler; GRANT USAGE ON SCHEMA auth TO scheduler;
GRANT SELECT ON ALL TABLES IN SCHEMA auth TO scheduler; GRANT SELECT ON ALL TABLES IN SCHEMA auth TO scheduler;
GRANT SELECT,UPDATE ON TABLE auth.otp TO scheduler; GRANT SELECT,UPDATE,DELETE ON TABLE auth.otp TO scheduler;
--------------------------------------------------------------------------- ---------------------------------------------------------------------------
-- Security policy -- Security policy
@@ -258,15 +258,12 @@ CREATE POLICY admin_all ON auth.vessels TO current_user
WITH CHECK (true); WITH CHECK (true);
-- Allow user_role to update and select on their own records -- Allow user_role to update and select on their own records
CREATE POLICY api_user_role ON auth.vessels TO user_role CREATE POLICY api_user_role ON auth.vessels TO user_role
USING (mmsi = current_setting('vessel.mmsi', true) USING (vessel_id = current_setting('vessel.id', true)
AND owner_email = current_setting('user.email', true) AND owner_email = current_setting('user.email', true)
) )
WITH CHECK (mmsi = current_setting('vessel.mmsi', false) WITH CHECK (vessel_id = current_setting('vessel.id', true)
AND owner_email = current_setting('user.email', true) AND owner_email = current_setting('user.email', true)
); );
--CREATE POLICY grafana_role ON auth.vessels TO grafana
-- USING (owner_email = owner_email)
-- WITH CHECK (owner_email = owner_email);
-- Be sure to enable row level security on the table -- Be sure to enable row level security on the table
ALTER TABLE auth.accounts ENABLE ROW LEVEL SECURITY; ALTER TABLE auth.accounts ENABLE ROW LEVEL SECURITY;
@@ -280,3 +277,6 @@ CREATE POLICY api_user_role ON auth.accounts TO user_role
) )
WITH CHECK (email = current_setting('user.email', true) WITH CHECK (email = current_setting('user.email', true)
); );
--CREATE POLICY grafana_proxy_role ON auth.accounts TO grafana_auth
-- USING (owner_email = owner_email)
-- WITH CHECK (owner_email = owner_email);