diff --git a/initdb/02_3_2_signalk_public_functions.sql b/initdb/02_3_2_signalk_public_functions.sql index b45f61d..3941440 100644 --- a/initdb/02_3_2_signalk_public_functions.sql +++ b/initdb/02_3_2_signalk_public_functions.sql @@ -1568,11 +1568,13 @@ CREATE OR REPLACE FUNCTION public.check_jwt() RETURNS void AS $$ DECLARE _role name; _email text; - _mmsi name; + anonymous record; _path name; _vid text; _vname text; + boat TEXT; _pid INTEGER := 0; -- public_id + _pvessel TEXT := NULL; -- public_type _ptype TEXT := NULL; -- public_type _ppath BOOLEAN := False; -- public_path _pvalid BOOLEAN := False; -- public_valid @@ -1605,16 +1607,19 @@ BEGIN END IF; -- Set session variables PERFORM set_config('user.id', account_rec.user_id, false); + SELECT current_setting('request.path', true) into _path; --RAISE WARNING 'req path %', current_setting('request.path', true); - -- Function allow without defined vessel + -- Function allow without defined vessel like for anonymous role + IF _path ~ '^\/rpc\/(login|signup|recover|reset)$' THEN + RETURN; + END IF; + -- Function allow without defined vessel as user role -- openapi doc, user settings, otp code and vessel registration - SELECT current_setting('request.path', true) into _path; IF _path = '/rpc/settings_fn' OR _path = '/rpc/register_vessel' OR _path = '/rpc/update_user_preferences_fn' OR _path = '/rpc/versions_fn' OR _path = '/rpc/email_fn' - OR _path = '/rpc/login' OR _path = '/' THEN RETURN; END IF; @@ -1626,10 +1631,10 @@ BEGIN -- check if boat exist yet? IF vessel_rec.owner_email IS NULL THEN -- Return http status code 551 with message - RAISE sqlstate 'PT551' using - message = 'Vessel Required', - detail = 'Invalid vessel', - hint = 'Unknown vessel'; + RAISE sqlstate 'PT551' using + message = 'Vessel Required', + detail = 'Invalid vessel', + hint = 'Unknown vessel'; --RETURN; -- ignore if not exist END IF; -- Redundant? @@ -1662,80 +1667,85 @@ BEGIN ELSIF _role = 'api_anonymous' THEN RAISE WARNING 'public.check_jwt() api_anonymous'; -- Check if path is the a valid allow anonymous path - SELECT current_setting('request.path', true) ~ '/(logs_view|log_view|rpc/timelapse_fn|monitoring_view|stats_logs_view|stats_moorages_view|rpc/stats_logs_fn)$' INTO _ppath; + SELECT current_setting('request.path', true) ~ '^/(logs_view|log_view|rpc/timelapse_fn|monitoring_view|stats_logs_view|stats_moorages_view|rpc/stats_logs_fn)$' INTO _ppath; if _ppath is True then -- Check is custom header is present and valid - select current_setting('request.headers', true)::json->>'x-is-public' into _pheader; + SELECT current_setting('request.headers', true)::json->>'x-is-public' into _pheader; RAISE WARNING 'public.check_jwt() api_anonymous _pheader [%]', _pheader; if _pheader is null then RAISE EXCEPTION 'Invalid public_header' USING HINT = 'Stop being so evil and maybe you can log in'; end if; - select convert_from(decode(_pheader, 'base64'), 'utf-8') - ~ '\d+,public_(logs|logs_list|stats|timelapse|monitoring)$' into _pvalid; + SELECT convert_from(decode(_pheader, 'base64'), 'utf-8') + ~ '\w+,public_(logs|logs_list|stats|timelapse|monitoring),\d+$' into _pvalid; RAISE WARNING 'public.check_jwt() api_anonymous _pvalid [%]', _pvalid; if _pvalid is null or _pvalid is False then RAISE EXCEPTION 'Invalid public_valid' USING HINT = 'Stop being so evil and maybe you can log in'; end if; WITH regex AS ( - select regexp_match( + SELECT regexp_match( convert_from( decode(_pheader, 'base64'), 'utf-8'), - '(\d+),(public_(logs|logs_list|stats|timelapse|monitoring))$') AS match + '(\w+),(public_(logs|logs_list|stats|timelapse|monitoring)),(\d+)$') AS match ) - SELECT match[1], match[2] into _pid, _ptype + SELECT match[1], match[2], match[4] into _pvessel, _ptype, _pid FROM regex; - RAISE WARNING 'public.check_jwt() api_anonymous [%] [%]', _pid, _ptype; - if _pid is not null and _pid > 0 then - -- Everything seem fine, get the vessel_id base on the id. + RAISE WARNING 'public.check_jwt() api_anonymous [%] [%] [%]', _pvessel, _ptype, _pid; + if _pvessel is not null and _ptype is not null then + -- Everything seem fine, get the vessel_id base on the vessel name. SELECT _ptype::name = any(enum_range(null::public_type)::name[]) INTO valid_public_type; IF valid_public_type IS False THEN -- Ignore entry if type is invalid RAISE EXCEPTION 'Invalid public_type' USING HINT = 'Stop being so evil and maybe you can log in'; END IF; - IF _ptype = 'public_logs' THEN + -- Check if boat name match public_vessel name + boat := '^' || _pvessel || '$'; + IF _ptype ~ '^public_(logs|timelapse)$' AND _pid IS NOT NULL THEN WITH log as ( - select vessel_id from api.logbook l where l.id = _pid::INTEGER + SELECT vessel_id from api.logbook l where l.id = _pid ) - SELECT l.vessel_id into _vid + SELECT v.vessel_id, v.name into anonymous FROM auth.accounts a, auth.vessels v, jsonb_each_text(a.preferences) as prefs, log l WHERE v.vessel_id = l.vessel_id - AND a.email = v.owner_email - AND prefs.key = 'public_logs'::TEXT - AND prefs.value::BOOLEAN = true; - IF FOUND THEN - -- Set session variables - PERFORM set_config('vessel.id', _vid, false); + AND a.email = v.owner_email + AND a.preferences->>'public_vessel'::text ~* boat + AND prefs.key = _ptype::TEXT + AND prefs.value::BOOLEAN = true; + RAISE WARNING '-> ispublic_fn public_logs output boat:[%], type:[%], result:[%]', _pvessel, _ptype, anonymous; + IF anonymous.vessel_id IS NOT NULL THEN + PERFORM set_config('vessel.id', anonymous.vessel_id, false); + PERFORM set_config('vessel.name', anonymous.name, false); RETURN; END IF; ELSE - SELECT v.vessel_id, v.name into _vid, _vname - FROM auth.accounts a, auth.vessels v, jsonb_each_text(a.preferences) as prefs - WHERE a.public_id = _pid::INTEGER - AND a.email = v.owner_email + SELECT v.vessel_id, v.name into anonymous + FROM auth.accounts a, auth.vessels v, jsonb_each_text(a.preferences) as prefs + WHERE a.email = v.owner_email + AND a.preferences->>'public_vessel'::text ~* boat AND prefs.key = _ptype::TEXT AND prefs.value::BOOLEAN = true; - IF FOUND THEN - -- Set session variables - PERFORM set_config('vessel.id', _vid, false); - PERFORM set_config('vessel.name', _vname, false); + RAISE WARNING '-> ispublic_fn output boat:[%], type:[%], result:[%]', _pvessel, _ptype, anonymous; + IF anonymous.vessel_id IS NOT NULL THEN + PERFORM set_config('vessel.id', anonymous.vessel_id, false); + PERFORM set_config('vessel.name', anonymous.name, false); RETURN; END IF; END IF; - -- Reached if the user did not allow public access for '_ptype', return HTTP/401 - --RAISE EXCEPTION 'Invalid anonymous access' - -- USING HINT = 'Stop being so evil and maybe you can log in'; - RAISE insufficient_privilege USING MESSAGE = 'Invalid anonymous access'; - end if; -- end anonymous path - end if; + RAISE sqlstate 'PT404' using message = 'unknown resource'; + END IF; -- end anonymous path + END IF; ELSIF _role <> 'api_anonymous' THEN RAISE EXCEPTION 'Invalid role' USING HINT = 'Stop being so evil and maybe you can log in'; END IF; END $$ language plpgsql security definer; +-- Description +COMMENT ON FUNCTION + public.check_jwt + IS 'PostgREST API db-pre-request check, set_config according to role (api_anonymous,vessel_role,user_role)'; --------------------------------------------------------------------------- -- Function to trigger cron_jobs using API for tests. diff --git a/initdb/02_4_signalk_auth.sql b/initdb/02_4_signalk_auth.sql index 8acdcf9..4c98b53 100644 --- a/initdb/02_4_signalk_auth.sql +++ b/initdb/02_4_signalk_auth.sql @@ -21,7 +21,6 @@ CREATE EXTENSION IF NOT EXISTS "pgcrypto"; -- provides cryptographic functions DROP TABLE IF EXISTS auth.accounts CASCADE; CREATE TABLE IF NOT EXISTS auth.accounts ( - public_id SERIAL UNIQUE NOT NULL, user_id TEXT NOT NULL UNIQUE DEFAULT RIGHT(gen_random_uuid()::text, 12), email CITEXT PRIMARY KEY CHECK ( email ~* '^.+@.+\..+$' ), first TEXT NOT NULL CHECK (length(pass) < 512), @@ -42,11 +41,7 @@ COMMENT ON TABLE auth.accounts IS 'users account table'; -- Indexes --- is unused index? ---CREATE INDEX accounts_role_idx ON auth.accounts (role); CREATE INDEX accounts_preferences_idx ON auth.accounts USING GIN (preferences); -CREATE INDEX accounts_public_id_idx ON auth.accounts (public_id); -COMMENT ON COLUMN auth.accounts.public_id IS 'User public_id to allow mapping for anonymous access, could be use as well for as Grafana orgId'; COMMENT ON COLUMN auth.accounts.first IS 'User first name with CONSTRAINT CHECK'; COMMENT ON COLUMN auth.accounts.last IS 'User last name with CONSTRAINT CHECK'; @@ -61,7 +56,7 @@ COMMENT ON TRIGGER accounts_moddatetime DROP TABLE IF EXISTS auth.vessels; CREATE TABLE IF NOT EXISTS auth.vessels ( - vessel_id TEXT NOT NULL UNIQUE DEFAULT RIGHT(gen_random_uuid()::text, 12), + vessel_id TEXT NOT NULL UNIQUE DEFAULT RIGHT(gen_random_uuid()::text, 12), -- user_id TEXT NOT NULL REFERENCES auth.accounts(user_id) ON DELETE RESTRICT, owner_email CITEXT PRIMARY KEY REFERENCES auth.accounts(email) ON DELETE RESTRICT, -- mmsi TEXT UNIQUE, -- Should be a numeric range between 100000000 and 800000000. @@ -79,10 +74,6 @@ COMMENT ON TABLE auth.vessels IS 'vessels table link to accounts email user_id column'; -- Indexes --- is unused index? ---CREATE INDEX vessels_role_idx ON auth.vessels (role); --- is unused index? ---CREATE INDEX vessels_name_idx ON auth.vessels (name); CREATE INDEX vessels_vesselid_idx ON auth.vessels (vessel_id); CREATE TRIGGER vessels_moddatetime @@ -275,6 +266,8 @@ begin vessel_rec.role := 'vessel_role'; vessel_rec.owner_email = vessel_email; vessel_rec.vessel_id = _vessel_id; + -- Update user settings with a public vessel name + PERFORM api.update_user_preferences_fn('{public_vessel}', vessel_name); END IF; -- Get app_jwt_secret diff --git a/initdb/02_5_signalk_api_deps.sql b/initdb/02_5_signalk_api_deps.sql index ecbae63..8009190 100644 --- a/initdb/02_5_signalk_api_deps.sql +++ b/initdb/02_5_signalk_api_deps.sql @@ -20,7 +20,16 @@ COMMENT ON COLUMN api.metadata.vessel_id IS 'Link auth.vessels with api.metadata -- REFERENCE ship type with AIS type ? -- REFERENCE mmsi MID with country ? - +ALTER TABLE api.logbook ADD FOREIGN KEY (_from_moorage_id) REFERENCES api.moorages(id) ON DELETE RESTRICT; +COMMENT ON COLUMN api.logbook._from_moorage_id IS 'Link api.moorages with api.logbook via FOREIGN KEY and REFERENCES'; +ALTER TABLE api.logbook ADD FOREIGN KEY (_to_moorage_id) REFERENCES api.moorages(id) ON DELETE RESTRICT; +COMMENT ON COLUMN api.logbook._to_moorage_id IS 'Link api.moorages with api.logbook via FOREIGN KEY and REFERENCES'; +ALTER TABLE api.stays ADD FOREIGN KEY (moorage_id) REFERENCES api.moorages(id) ON DELETE RESTRICT; +COMMENT ON COLUMN api.stays.moorage_id IS 'Link api.moorages with api.stays via FOREIGN KEY and REFERENCES'; +ALTER TABLE api.stays ADD FOREIGN KEY (stay_code) REFERENCES api.stays_at(stay_code) ON DELETE RESTRICT; +COMMENT ON COLUMN api.stays.stay_code IS 'Link api.stays_at with api.stays via FOREIGN KEY and REFERENCES'; +ALTER TABLE api.moorages ADD FOREIGN KEY (stay_code) REFERENCES api.stays_at(stay_code) ON DELETE RESTRICT; +COMMENT ON COLUMN api.moorages.stay_code IS 'Link api.stays_at with api.moorages via FOREIGN KEY and REFERENCES'; -- List vessel --TODO add geojson with position @@ -140,12 +149,11 @@ AS $user_settings$ from ( select a.email, a.first, a.last, a.preferences, a.created_at, INITCAP(CONCAT (LEFT(first, 1), ' ', last)) AS username, - public.has_vessel_fn() as has_vessel, + public.has_vessel_fn() as has_vessel --public.has_vessel_metadata_fn() as has_vessel_metadata, - a.public_id from auth.accounts a where email = current_setting('user.email') - ) row; + ) row; END; $user_settings$ language plpgsql security definer; -- Description @@ -287,15 +295,16 @@ COMMENT ON FUNCTION IS 'Update/Add logbook observations jsonb key pair value'; CREATE TYPE public_type AS ENUM ('public_logs', 'public_logs_list', 'public_timelapse', 'public_monitoring', 'public_stats'); -CREATE FUNCTION api.ispublic_fn(IN id INTEGER, IN _type public_type) RETURNS BOOLEAN AS $ispublic$ +CREATE or replace FUNCTION api.ispublic_fn(IN boat TEXT, IN _type TEXT, IN _id INTEGER DEFAULT NULL) RETURNS BOOLEAN AS $ispublic$ DECLARE - _id INTEGER := id; - rec record; + vessel TEXT := '^' || boat || '$'; + anonymous BOOLEAN := False; valid_public_type BOOLEAN := False; + public_logs BOOLEAN := False; BEGIN - -- If _id is is not NULL and > 0 - IF _id IS NULL OR _id < 1 THEN - RAISE WARNING '-> ispublic_fn invalid input %', _id; + -- If boat is not NULL + IF boat IS NULL THEN + RAISE WARNING '-> ispublic_fn invalid input %', boat; RETURN False; END IF; -- Check if public_type is valid enum @@ -306,32 +315,35 @@ BEGIN RETURN False; END IF; - IF _type = 'public_logs' THEN + IF _type ~ '^public_(logs|timelapse)$' AND _id IS NOT NULL THEN WITH log as ( - select vessel_id from api.logbook l where l.id = _id::INTEGER + SELECT vessel_id from api.logbook l where l.id = _id ) SELECT EXISTS ( SELECT l.vessel_id FROM auth.accounts a, auth.vessels v, jsonb_each_text(a.preferences) as prefs, log l WHERE v.vessel_id = l.vessel_id AND a.email = v.owner_email - AND prefs.key = 'public_logs'::TEXT + AND a.preferences->>'public_vessel'::text ~* vessel + AND prefs.key = _type::TEXT AND prefs.value::BOOLEAN = true - ) into rec; - IF FOUND THEN - RETURN True; - END IF; + ) into anonymous; + RAISE WARNING '-> ispublic_fn public_logs output boat:[%], type:[%], result:[%]', boat, _type, anonymous; + IF anonymous IS True THEN + RETURN True; + END IF; ELSE - SELECT EXISTS ( - SELECT a.email, a.preferences - FROM auth.accounts a, jsonb_each_text(a.preferences) as prefs - WHERE a.public_id = _id - AND prefs.key = '|| _type ||'::TEXT - AND prefs.value::BOOLEAN = true - ) into rec; - IF FOUND THEN - RETURN True; - END IF; + SELECT EXISTS ( + SELECT a.email + FROM auth.accounts a, jsonb_each_text(a.preferences) as prefs + WHERE a.preferences->>'public_vessel'::text ~* vessel + AND prefs.key = _type::TEXT + AND prefs.value::BOOLEAN = true + ) into anonymous; + RAISE WARNING '-> ispublic_fn output boat:[%], type:[%], result:[%]', boat, _type, anonymous; + IF anonymous IS True THEN + RETURN True; + END IF; END IF; RETURN False; END @@ -339,4 +351,4 @@ $ispublic$ language plpgsql security definer; -- Description COMMENT ON FUNCTION api.ispublic_fn - IS 'Is web page publicly accessible?'; + IS 'Is web page publicly accessible by register boat name and/or logbook id'; diff --git a/initdb/02_6_signalk_roles.sql b/initdb/02_6_signalk_roles.sql index ca38ec8..890fdfb 100644 --- a/initdb/02_6_signalk_roles.sql +++ b/initdb/02_6_signalk_roles.sql @@ -38,7 +38,17 @@ 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_otp_fn(text) to api_anonymous; --grant execute on function api.generate_otp_fn(text) to api_anonymous; -grant execute on function api.ispublic_fn(integer,public_type) to api_anonymous; +grant execute on function api.ispublic_fn(text,text,integer) to api_anonymous; +grant execute on function api.timelapse_fn to api_anonymous; +-- Allow read on TABLES on API schema +--GRANT SELECT ON TABLE api.metrics,api.logbook,api.moorages,api.stays,api.metadata,api.stays_at TO api_anonymous; +-- Allow read on VIEWS on API schema +--GRANT SELECT ON TABLE api.logs_view,api.moorages_view,api.stays_view TO api_anonymous; +--GRANT SELECT ON TABLE api.log_view,api.moorage_view,api.stay_view,api.vessels_view TO api_anonymous; +GRANT SELECT ON ALL TABLES IN SCHEMA api TO api_anonymous; +GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public TO api_anonymous; +--grant execute on function public.st_asgeojson(record,text,integer,boolean) to api_anonymous; +--grant execute on function public.st_makepoint(float,float) to api_anonymous; -- authenticator -- login role @@ -97,9 +107,11 @@ GRANT SELECT ON TABLE public.process_queue TO user_role; -- To check? GRANT SELECT ON TABLE auth.vessels TO user_role; -- Allow users to update certain columns on specific TABLES on API schema -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, _from, _to, notes) ON api.logbook TO user_role; +GRANT UPDATE (name, notes, stay_code, active, departed) ON api.stays TO user_role; GRANT UPDATE (name, notes, stay_code, home_flag) ON api.moorages TO user_role; +-- Allow users to remove logs and stays +GRANT DELETE ON api.logbook,api.stays,api.moorages TO user_role; -- Allow EXECUTE on all FUNCTIONS on API and public schema GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA api TO user_role; GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public TO user_role; @@ -115,6 +127,7 @@ GRANT SELECT ON TABLE api.stats_logs_view TO user_role; GRANT SELECT ON TABLE api.stats_moorages_view TO user_role; GRANT SELECT ON TABLE api.eventlogs_view TO user_role; GRANT SELECT ON TABLE api.vessels_view TO user_role; +GRANT SELECT ON TABLE api.moorages_stays_view TO user_role; -- Vessel: -- nologin @@ -137,7 +150,8 @@ GRANT EXECUTE ON FUNCTION public.trip_in_progress_fn(text) to vessel_role; GRANT EXECUTE ON FUNCTION public.stay_in_progress_fn(text) to vessel_role; -- hypertable get_partition_hash ?!? GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA _timescaledb_internal TO vessel_role; - +-- on metrics st_makepoint +GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public TO vessel_role; --- Scheduler: -- TODO: currently cron function are run as super user, switch to scheduler role. @@ -209,6 +223,10 @@ CREATE POLICY api_scheduler_role ON api.metrics TO scheduler CREATE POLICY grafana_role ON api.metrics TO grafana USING (vessel_id = current_setting('vessel.id', false)) WITH CHECK (false); +-- Allow anonymous to select based on the vessel.id +CREATE POLICY api_anonymous_role ON api.metrics TO api_anonymous + USING (vessel_id = current_setting('vessel.id', false)) + WITH CHECK (false); -- Be sure to enable row level security on the table ALTER TABLE api.logbook ENABLE ROW LEVEL SECURITY; @@ -233,6 +251,10 @@ CREATE POLICY api_scheduler_role ON api.logbook TO scheduler CREATE POLICY grafana_role ON api.logbook TO grafana USING (vessel_id = current_setting('vessel.id', false)) WITH CHECK (false); +-- Allow anonymous to select based on the vessel.id +CREATE POLICY api_anonymous_role ON api.logbook TO api_anonymous + USING (vessel_id = current_setting('vessel.id', false)) + WITH CHECK (false); -- Be sure to enable row level security on the table ALTER TABLE api.stays ENABLE ROW LEVEL SECURITY;