diff --git a/initdb/02_5_signalk_api_deps.sql b/initdb/02_5_signalk_api_deps.sql index bf101d9..584dbf2 100644 --- a/initdb/02_5_signalk_api_deps.sql +++ b/initdb/02_5_signalk_api_deps.sql @@ -1,6 +1,6 @@ --------------------------------------------------------------------------- --- singalk db permissions --- +-- singalk db api schema +-- View and Function that have dependency with auth schema -- List current database select current_database(); @@ -34,6 +34,7 @@ CREATE OR REPLACE VIEW api.vessel_p_view AS WHERE lower(v.owner_email) = lower(current_setting('request.jwt.claims', true)::json->>'email'); -- Or function? +-- TODO Improve: return null until the vessel has sent metadata? DROP FUNCTION IF EXISTS api.vessel_fn; CREATE OR REPLACE FUNCTION api.vessel_fn(OUT vessel JSON) RETURNS JSON AS $vessel$ @@ -44,8 +45,8 @@ AS $vessel$ 'name', v.name, 'mmsi', v.mmsi, 'created_at', v.created_at, - 'last_contact', m.time, - 'geojson', ST_AsGeoJSON(geojson_t.*)::json + 'last_contact', coalesce(m.time, null), + 'geojson', coalesce(ST_AsGeoJSON(geojson_t.*)::json, null) ) INTO vessel FROM auth.vessels v, api.metadata m, @@ -64,7 +65,6 @@ AS $vessel$ WHERE latitude IS NOT NULL AND longitude IS NOT NULL - AND client_id LIKE '%' || current_setting('vessel.mmsi', false) ) ) AS t ) AS geojson_t @@ -93,7 +93,6 @@ AS $user_settings$ ) row; END; $user_settings$ language plpgsql security definer; - -- Description COMMENT ON FUNCTION api.settings_fn @@ -117,7 +116,7 @@ $version$ language plpgsql security definer; -- Description COMMENT ON FUNCTION api.versions_fn - IS 'Expose function app and system version to API'; + IS 'Expose as a function, app and system version to API'; DROP VIEW IF EXISTS api.versions_view; CREATE OR REPLACE VIEW api.versions_view AS @@ -129,4 +128,70 @@ CREATE OR REPLACE VIEW api.versions_view AS -- Description COMMENT ON VIEW api.versions_view - IS 'Expose view app and system version to API'; + IS 'Expose as a table view app and system version to API'; + +CREATE OR REPLACE FUNCTION public.isnumeric(text) RETURNS BOOLEAN AS +$isnumeric$ +DECLARE x NUMERIC; +BEGIN + x = $1::NUMERIC; + RETURN TRUE; +EXCEPTION WHEN others THEN + RETURN FALSE; +END; +$isnumeric$ +STRICT +LANGUAGE plpgsql IMMUTABLE; +-- Description +COMMENT ON FUNCTION + public.isnumeric + IS 'Check typeof value is numeric'; + +CREATE OR REPLACE FUNCTION public.isboolean(text) RETURNS BOOLEAN AS +$isboolean$ +DECLARE x BOOLEAN; +BEGIN + x = $1::BOOLEAN; + RETURN TRUE; +EXCEPTION WHEN others THEN + RETURN FALSE; +END; +$isboolean$ +STRICT +LANGUAGE plpgsql IMMUTABLE; +-- Description +COMMENT ON FUNCTION + public.isboolean + IS 'Check typeof value is boolean'; + +DROP FUNCTION IF EXISTS api.update_user_preferences_fn; +-- Update/Add a specific user setting into preferences +CREATE OR REPLACE FUNCTION api.update_user_preferences_fn(IN key TEXT, IN value TEXT) RETURNS BOOLEAN AS +$update_user_preferences$ +DECLARE + first_c TEXT := NULL; + last_c TEXT := NULL; + _value TEXT := value; +BEGIN + -- Is it the only way to check variable type? + -- Convert string to jsonb and skip type of json obj or integer or boolean + SELECT SUBSTRING(value, 1, 1),RIGHT(value, 1) INTO first_c,last_c; + IF first_c <> '{' AND last_c <> '}' AND public.isnumeric(value) IS False + AND public.isboolean(value) IS False THEN + --RAISE WARNING '-> first_c:[%] last_c:[%] pg_typeof:[%]', first_c,last_c,pg_typeof(value); + _value := to_jsonb(value)::jsonb; + END IF; + UPDATE auth.accounts + SET preferences = + jsonb_set(preferences::jsonb, key::text[], _value::jsonb) + WHERE lower(email) = lower(current_setting('request.jwt.claims', true)::json->>'email'); + IF FOUND THEN + RETURN True; + END IF; + RETURN False; +END; +$update_user_preferences$ language plpgsql security definer; +-- Description +COMMENT ON FUNCTION + api.update_user_preferences_fn + IS 'Update user preferences jsonb key pair value';