Update vessel dependency to vessel.id instead of client_id.

Large commit, to fix a long pending issue for vessel wihtout a proper client_id from signalk.
This commit is contained in:
xbgmsharp
2023-06-25 09:53:25 +02:00
parent b4dc93ba0e
commit 4d833999e8
5 changed files with 177 additions and 171 deletions

View File

@@ -82,9 +82,11 @@ UPDATE pg_language SET lanpltrusted = true WHERE lanname = 'plpython3u';
-- Metadata from signalk -- Metadata from signalk
CREATE TABLE IF NOT EXISTS api.metadata( CREATE TABLE IF NOT EXISTS api.metadata(
id SERIAL PRIMARY KEY, id SERIAL PRIMARY KEY,
name VARCHAR(150) NULL, name TEXT NULL,
mmsi NUMERIC NULL, mmsi NUMERIC NULL,
client_id VARCHAR(255) UNIQUE NOT NULL, client_id TEXT NULL,
-- vessel_id link auth.vessels with api.metadata
vessel_id TEXT NOT NULL UNIQUE,
length DOUBLE PRECISION NULL, length DOUBLE PRECISION NULL,
beam DOUBLE PRECISION NULL, beam DOUBLE PRECISION NULL,
height DOUBLE PRECISION NULL, height DOUBLE PRECISION NULL,
@@ -93,7 +95,6 @@ CREATE TABLE IF NOT EXISTS api.metadata(
signalk_version TEXT NOT NULL, signalk_version TEXT NOT NULL,
time TIMESTAMP WITHOUT TIME ZONE NOT NULL, -- should be rename to last_update !? time TIMESTAMP WITHOUT TIME ZONE NOT NULL, -- should be rename to last_update !?
active BOOLEAN DEFAULT True, -- trigger monitor online/offline active BOOLEAN DEFAULT True, -- trigger monitor online/offline
-- vessel_id link auth.vessels with api.metadata
created_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW(), created_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW(),
updated_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW() updated_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW()
); );
@@ -103,8 +104,8 @@ COMMENT ON TABLE
IS 'Stores metadata from vessel'; IS 'Stores metadata from vessel';
COMMENT ON COLUMN api.metadata.active IS 'trigger monitor online/offline'; COMMENT ON COLUMN api.metadata.active IS 'trigger monitor online/offline';
-- Index -- Index
CREATE INDEX metadata_client_id_idx ON api.metadata (client_id); CREATE INDEX metadata_vessel_id_idx ON api.metadata (vessel_id);
CREATE INDEX metadata_mmsi_idx ON api.metadata (mmsi); --CREATE INDEX metadata_mmsi_idx ON api.metadata (mmsi);
CREATE INDEX metadata_name_idx ON api.metadata (name); CREATE INDEX metadata_name_idx ON api.metadata (name);
--------------------------------------------------------------------------- ---------------------------------------------------------------------------
@@ -114,7 +115,9 @@ CREATE TYPE status AS ENUM ('sailing', 'motoring', 'moored', 'anchored');
-- Table api.metrics -- Table api.metrics
CREATE TABLE IF NOT EXISTS api.metrics ( CREATE TABLE IF NOT EXISTS api.metrics (
time TIMESTAMP WITHOUT TIME ZONE NOT NULL, time TIMESTAMP WITHOUT TIME ZONE NOT NULL,
client_id VARCHAR(255) NOT NULL REFERENCES api.metadata(client_id) ON DELETE RESTRICT, --client_id VARCHAR(255) NOT NULL REFERENCES api.metadata(client_id) ON DELETE RESTRICT,
client_id TEXT NULL,
vessel_id TEXT NOT NULL REFERENCES api.metadata(vessel_id) ON DELETE RESTRICT,
latitude DOUBLE PRECISION NULL, latitude DOUBLE PRECISION NULL,
longitude DOUBLE PRECISION NULL, longitude DOUBLE PRECISION NULL,
speedOverGround DOUBLE PRECISION NULL, speedOverGround DOUBLE PRECISION NULL,
@@ -123,7 +126,7 @@ CREATE TABLE IF NOT EXISTS api.metrics (
angleSpeedApparent DOUBLE PRECISION NULL, angleSpeedApparent DOUBLE PRECISION NULL,
status status NULL, status status NULL,
metrics jsonb NULL, metrics jsonb NULL,
CONSTRAINT valid_client_id CHECK (length(client_id) > 10), --CONSTRAINT valid_client_id CHECK (length(client_id) > 10),
CONSTRAINT valid_latitude CHECK (latitude >= -90 and latitude <= 90), CONSTRAINT valid_latitude CHECK (latitude >= -90 and latitude <= 90),
CONSTRAINT valid_longitude CHECK (longitude >= -180 and longitude <= 180) CONSTRAINT valid_longitude CHECK (longitude >= -180 and longitude <= 180)
); );
@@ -135,21 +138,22 @@ COMMENT ON COLUMN api.metrics.latitude IS 'With CONSTRAINT but allow NULL value
COMMENT ON COLUMN api.metrics.longitude IS 'With CONSTRAINT but allow NULL value to be ignored silently by trigger'; COMMENT ON COLUMN api.metrics.longitude IS 'With CONSTRAINT but allow NULL value to be ignored silently by trigger';
-- Index -- Index
CREATE INDEX ON api.metrics (client_id, time DESC); CREATE INDEX ON api.metrics (vessel_id, time DESC);
CREATE INDEX ON api.metrics (status, time DESC); CREATE INDEX ON api.metrics (status, time DESC);
-- json index?? -- json index??
CREATE INDEX ON api.metrics using GIN (metrics); CREATE INDEX ON api.metrics using GIN (metrics);
-- timescaledb hypertable -- timescaledb hypertable
--SELECT create_hypertable('api.metrics', 'time'); SELECT create_hypertable('api.metrics', 'time', chunk_time_interval => INTERVAL '7 day');
-- timescaledb hypertable with space partitions -- timescaledb hypertable with space partitions
SELECT create_hypertable('api.metrics', 'time', 'client_id', -- ERROR: new row for relation "_hyper_1_2_chunk" violates check constraint "constraint_4"
number_partitions => 2, -- ((_timescaledb_internal.get_partition_hash(vessel_id) < 1073741823))
chunk_time_interval => INTERVAL '7 day', --SELECT create_hypertable('api.metrics', 'time', 'vessel_id',
if_not_exists => true); -- number_partitions => 2,
-- chunk_time_interval => INTERVAL '7 day',
-- if_not_exists => true);
--------------------------------------------------------------------------- ---------------------------------------------------------------------------
-- Logbook -- Logbook
-- todo add clientid ref
-- todo add cosumption fuel? -- todo add cosumption fuel?
-- todo add engine hour? -- todo add engine hour?
-- todo add geom object http://epsg.io/4326 EPSG:4326 Unit: degres -- todo add geom object http://epsg.io/4326 EPSG:4326 Unit: degres
@@ -162,8 +166,9 @@ SELECT create_hypertable('api.metrics', 'time', 'client_id',
-- https://www.reddit.com/r/PostgreSQL/comments/di5mbr/postgresql_12_foreign_keys_and_partitioned_tables/f3tsoop/ -- https://www.reddit.com/r/PostgreSQL/comments/di5mbr/postgresql_12_foreign_keys_and_partitioned_tables/f3tsoop/
CREATE TABLE IF NOT EXISTS api.logbook( CREATE TABLE IF NOT EXISTS api.logbook(
id SERIAL PRIMARY KEY, id SERIAL PRIMARY KEY,
client_id VARCHAR(255) NOT NULL REFERENCES api.metadata(client_id) ON DELETE RESTRICT, --client_id VARCHAR(255) NOT NULL REFERENCES api.metadata(client_id) ON DELETE RESTRICT,
-- client_id VARCHAR(255) NOT NULL, --client_id VARCHAR(255) NULL,
vessel_id TEXT NOT NULL REFERENCES api.metadata(vessel_id) ON DELETE RESTRICT,
active BOOLEAN DEFAULT false, active BOOLEAN DEFAULT false,
name VARCHAR(255), name VARCHAR(255),
_from VARCHAR(255), _from VARCHAR(255),
@@ -176,7 +181,7 @@ CREATE TABLE IF NOT EXISTS api.logbook(
track_geom geometry(LINESTRING,4326) NULL, track_geom geometry(LINESTRING,4326) NULL,
track_geog geography(LINESTRING) NULL, track_geog geography(LINESTRING) NULL,
track_geojson JSON NULL, track_geojson JSON NULL,
-- track_gpx XML NULL, track_gpx XML NULL,
_from_time TIMESTAMP WITHOUT TIME ZONE NOT NULL, _from_time TIMESTAMP WITHOUT TIME ZONE NOT NULL,
_to_time TIMESTAMP WITHOUT TIME ZONE NULL, _to_time TIMESTAMP WITHOUT TIME ZONE NULL,
distance NUMERIC, -- meters? distance NUMERIC, -- meters?
@@ -193,24 +198,23 @@ COMMENT ON TABLE
COMMENT ON COLUMN api.logbook.distance IS 'in NM'; COMMENT ON COLUMN api.logbook.distance IS 'in NM';
-- Index todo! -- Index todo!
CREATE INDEX logbook_client_id_idx ON api.logbook (client_id); CREATE INDEX logbook_vessel_id_idx ON api.logbook (vessel_id);
CREATE INDEX ON api.logbook USING GIST ( track_geom ); CREATE INDEX ON api.logbook USING GIST ( track_geom );
COMMENT ON COLUMN api.logbook.track_geom IS 'postgis geometry type EPSG:4326 Unit: degres'; COMMENT ON COLUMN api.logbook.track_geom IS 'postgis geometry type EPSG:4326 Unit: degres';
CREATE INDEX ON api.logbook USING GIST ( track_geog ); CREATE INDEX ON api.logbook USING GIST ( track_geog );
COMMENT ON COLUMN api.logbook.track_geog IS 'postgis geography type default SRID 4326 Unit: degres'; COMMENT ON COLUMN api.logbook.track_geog IS 'postgis geography type default SRID 4326 Unit: degres';
-- Otherwise -- ERROR: Only lon/lat coordinate systems are supported in geography. -- Otherwise -- ERROR: Only lon/lat coordinate systems are supported in geography.
COMMENT ON COLUMN api.logbook.track_geojson IS 'store the geojson track metrics data, can not depend api.metrics table, should be generate from linetring to save disk space?'; COMMENT ON COLUMN api.logbook.track_geojson IS 'store the geojson track metrics data, can not depend api.metrics table, should be generate from linetring to save disk space?';
--COMMENT ON COLUMN api.logbook.track_gpx IS 'store the gpx track metrics data, can not depend api.metrics table, should be generate from linetring to save disk space?'; COMMENT ON COLUMN api.logbook.track_gpx IS 'store the gpx track metrics data, can not depend api.metrics table, should be generate from linetring to save disk space?';
--------------------------------------------------------------------------- ---------------------------------------------------------------------------
-- Stays -- Stays
-- todo add clientid ref
-- todo add FOREIGN KEY?
-- virtual logbook by boat? -- virtual logbook by boat?
CREATE TABLE IF NOT EXISTS api.stays( CREATE TABLE IF NOT EXISTS api.stays(
id SERIAL PRIMARY KEY, id SERIAL PRIMARY KEY,
client_id VARCHAR(255) NOT NULL REFERENCES api.metadata(client_id) ON DELETE RESTRICT, --client_id VARCHAR(255) NOT NULL REFERENCES api.metadata(client_id) ON DELETE RESTRICT,
-- client_id VARCHAR(255) NOT NULL, --client_id VARCHAR(255) NULL,
vessel_id TEXT NOT NULL REFERENCES api.metadata(vessel_id) ON DELETE RESTRICT,
active BOOLEAN DEFAULT false, active BOOLEAN DEFAULT false,
name VARCHAR(255), name VARCHAR(255),
latitude DOUBLE PRECISION NULL, latitude DOUBLE PRECISION NULL,
@@ -228,21 +232,21 @@ COMMENT ON TABLE
IS 'Stores generated stays'; IS 'Stores generated stays';
-- Index -- Index
CREATE INDEX stays_client_id_idx ON api.stays (client_id); CREATE INDEX stays_vessel_id_idx ON api.stays (vessel_id);
CREATE INDEX ON api.stays USING GIST ( geog ); CREATE INDEX ON api.stays USING GIST ( geog );
COMMENT ON COLUMN api.stays.geog IS 'postgis geography type default SRID 4326 Unit: degres'; COMMENT ON COLUMN api.stays.geog IS 'postgis geography type default SRID 4326 Unit: degres';
-- With other SRID ERROR: Only lon/lat coordinate systems are supported in geography. -- With other SRID ERROR: Only lon/lat coordinate systems are supported in geography.
--------------------------------------------------------------------------- ---------------------------------------------------------------------------
-- Moorages -- Moorages
-- todo add clientid ref
-- virtual logbook by boat? -- virtual logbook by boat?
CREATE TABLE IF NOT EXISTS api.moorages( CREATE TABLE IF NOT EXISTS api.moorages(
id SERIAL PRIMARY KEY, id SERIAL PRIMARY KEY,
client_id VARCHAR(255) NOT NULL REFERENCES api.metadata(client_id) ON DELETE RESTRICT, --client_id VARCHAR(255) NOT NULL REFERENCES api.metadata(client_id) ON DELETE RESTRICT,
-- client_id VARCHAR(255) NOT NULL, --client_id VARCHAR(255) NULL,
name VARCHAR(255), vessel_id TEXT NOT NULL REFERENCES api.metadata(vessel_id) ON DELETE RESTRICT,
country VARCHAR(255), -- todo need to update reverse_geocode_py_fn name TEXT,
country TEXT, -- todo need to update reverse_geocode_py_fn
stay_id INT NOT NULL, -- needed? stay_id INT NOT NULL, -- needed?
stay_code INT DEFAULT 1, -- needed? REFERENCES api.stays_at(stay_code) stay_code INT DEFAULT 1, -- needed? REFERENCES api.stays_at(stay_code)
stay_duration INTERVAL NULL, stay_duration INTERVAL NULL,
@@ -259,7 +263,7 @@ COMMENT ON TABLE
IS 'Stores generated moorages'; IS 'Stores generated moorages';
-- Index -- Index
CREATE INDEX moorages_client_id_idx ON api.moorages (client_id); CREATE INDEX moorages_vessel_id_idx ON api.moorages (vessel_id);
CREATE INDEX ON api.moorages USING GIST ( geog ); CREATE INDEX ON api.moorages USING GIST ( geog );
COMMENT ON COLUMN api.moorages.geog IS 'postgis geography type default SRID 4326 Unit: degres'; COMMENT ON COLUMN api.moorages.geog IS 'postgis geography type default SRID 4326 Unit: degres';
-- With other SRID ERROR: Only lon/lat coordinate systems are supported in geography. -- With other SRID ERROR: Only lon/lat coordinate systems are supported in geography.
@@ -290,13 +294,13 @@ CREATE FUNCTION metadata_upsert_trigger_fn() RETURNS trigger AS $metadata_upsert
metadata_active boolean; metadata_active boolean;
BEGIN BEGIN
-- Set client_id to new value to allow RLS -- Set client_id to new value to allow RLS
PERFORM set_config('vessel.client_id', NEW.client_id, false); --PERFORM set_config('vessel.client_id', NEW.client_id, false);
-- UPSERT - Insert vs Update for Metadata -- UPSERT - Insert vs Update for Metadata
RAISE NOTICE 'metadata_upsert_trigger_fn'; RAISE NOTICE 'metadata_upsert_trigger_fn';
RAISE WARNING 'metadata_upsert_trigger_fn [%] [%]', current_setting('vessel.id', true), NEW;
SELECT m.id,m.active INTO metadata_id, metadata_active SELECT m.id,m.active INTO metadata_id, metadata_active
FROM api.metadata m FROM api.metadata m
WHERE (m.vessel_id IS NOT NULL AND m.vessel_id = current_setting('vessel.id', true)) WHERE m.vessel_id IS NOT NULL AND m.vessel_id = current_setting('vessel.id', true);
OR (m.client_id IS NOT NULL AND m.client_id = NEW.client_id);
RAISE NOTICE 'metadata_id %', metadata_id; RAISE NOTICE 'metadata_id %', metadata_id;
IF metadata_id IS NOT NULL THEN IF metadata_id IS NOT NULL THEN
-- send notifitacion if boat is back online -- send notifitacion if boat is back online
@@ -397,14 +401,15 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
valid_status BOOLEAN; valid_status BOOLEAN;
BEGIN BEGIN
-- Set client_id to new value to allow RLS -- Set client_id to new value to allow RLS
PERFORM set_config('vessel.client_id', NEW.client_id, false); --PERFORM set_config('vessel.client_id', NEW.client_id, false);
NEW.vessel_id = current_setting('vessel.id');
--RAISE NOTICE 'metrics_trigger_fn client_id [%]', NEW.client_id; --RAISE NOTICE 'metrics_trigger_fn client_id [%]', NEW.client_id;
-- Boat metadata are check using api.metrics REFERENCES to api.metadata -- Boat metadata are check using api.metrics REFERENCES to api.metadata
-- Fetch the latest entry to compare status against the new status to be insert -- Fetch the latest entry to compare status against the new status to be insert
SELECT coalesce(m.status, 'moored'), m.time INTO previous_status, previous_time SELECT coalesce(m.status, 'moored'), m.time INTO previous_status, previous_time
FROM api.metrics m FROM api.metrics m
WHERE m.client_id IS NOT NULL WHERE m.vessel_id IS NOT NULL
AND m.client_id = NEW.client_id AND m.vessel_id = current_setting('vessel.id', true)
ORDER BY m.time DESC LIMIT 1; ORDER BY m.time DESC LIMIT 1;
--RAISE NOTICE 'Metrics Status, New:[%] Previous:[%]', NEW.status, previous_status; --RAISE NOTICE 'Metrics Status, New:[%] Previous:[%]', NEW.status, previous_status;
IF previous_time = NEW.time THEN IF previous_time = NEW.time THEN
@@ -425,7 +430,7 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
END IF; END IF;
-- Check if status is null -- Check if status is null
IF NEW.status IS NULL THEN IF NEW.status IS NULL THEN
RAISE WARNING 'Metrics Unknow NEW.status from vessel [%], set to default moored', NEW.status; RAISE WARNING 'Metrics Unknow NEW.status from vessel [%], set to default moored', NEW;
NEW.status := 'moored'; NEW.status := 'moored';
END IF; END IF;
IF previous_status IS NULL THEN IF previous_status IS NULL THEN
@@ -438,8 +443,8 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
END IF; END IF;
-- Add new stay as no previous entry exist -- Add new stay as no previous entry exist
INSERT INTO api.stays INSERT INTO api.stays
(client_id, active, arrived, latitude, longitude, stay_code) (vessel_id, active, arrived, latitude, longitude, stay_code)
VALUES (NEW.client_id, true, NEW.time, NEW.latitude, NEW.longitude, 1) VALUES (current_setting('vessel.id', true), true, NEW.time, NEW.latitude, NEW.longitude, 1)
RETURNING id INTO stay_id; RETURNING id INTO stay_id;
-- Add stay entry to process queue for further processing -- Add stay entry to process queue for further processing
INSERT INTO process_queue (channel, payload, stored) INSERT INTO process_queue (channel, payload, stored)
@@ -461,11 +466,11 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
OR (NEW.status::TEXT = 'motoring' AND previous_status::TEXT <> 'sailing') ) THEN OR (NEW.status::TEXT = 'motoring' AND previous_status::TEXT <> 'sailing') ) THEN
RAISE WARNING 'Metrics Update status, try new logbook, New:[%] Previous:[%]', NEW.status, previous_status; RAISE WARNING 'Metrics Update status, try new logbook, New:[%] Previous:[%]', NEW.status, previous_status;
-- Start new log -- Start new log
logbook_id := public.trip_in_progress_fn(NEW.client_id::TEXT); logbook_id := public.trip_in_progress_fn(current_setting('vessel.id', true)::TEXT);
IF logbook_id IS NULL THEN IF logbook_id IS NULL THEN
INSERT INTO api.logbook INSERT INTO api.logbook
(client_id, active, _from_time, _from_lat, _from_lng) (vessel_id, active, _from_time, _from_lat, _from_lng)
VALUES (NEW.client_id, true, NEW.time, NEW.latitude, NEW.longitude) VALUES (current_setting('vessel.id', true), true, NEW.time, NEW.latitude, NEW.longitude)
RETURNING id INTO logbook_id; RETURNING id INTO logbook_id;
RAISE WARNING 'Metrics Insert new logbook, logbook_id %', logbook_id; RAISE WARNING 'Metrics Insert new logbook, logbook_id %', logbook_id;
ELSE ELSE
@@ -480,7 +485,7 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
END IF; END IF;
-- End current stay -- End current stay
stay_id := public.stay_in_progress_fn(NEW.client_id::TEXT); stay_id := public.stay_in_progress_fn(current_setting('vessel.id', true)::TEXT);
IF stay_id IS NOT NULL THEN IF stay_id IS NOT NULL THEN
UPDATE api.stays UPDATE api.stays
SET SET
@@ -501,7 +506,7 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
OR (NEW.status::TEXT = 'anchored' AND previous_status::TEXT <> 'moored') ) THEN OR (NEW.status::TEXT = 'anchored' AND previous_status::TEXT <> 'moored') ) THEN
-- Start new stays -- Start new stays
RAISE WARNING 'Metrics Update status, try new stay, New:[%] Previous:[%]', NEW.status, previous_status; RAISE WARNING 'Metrics Update status, try new stay, New:[%] Previous:[%]', NEW.status, previous_status;
stay_id := public.stay_in_progress_fn(NEW.client_id::TEXT); stay_id := public.stay_in_progress_fn(current_setting('vessel.id', true)::TEXT);
IF stay_id IS NULL THEN IF stay_id IS NULL THEN
RAISE WARNING 'Metrics Inserting new stay [%]', NEW.status; RAISE WARNING 'Metrics Inserting new stay [%]', NEW.status;
-- If metric status is anchored set stay_code accordingly -- If metric status is anchored set stay_code accordingly
@@ -511,8 +516,8 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
END IF; END IF;
-- Add new stay -- Add new stay
INSERT INTO api.stays INSERT INTO api.stays
(client_id, active, arrived, latitude, longitude, stay_code) (vessel_id, active, arrived, latitude, longitude, stay_code)
VALUES (NEW.client_id, true, NEW.time, NEW.latitude, NEW.longitude, stay_code) VALUES (current_setting('vessel.id', true), true, NEW.time, NEW.latitude, NEW.longitude, stay_code)
RETURNING id INTO stay_id; RETURNING id INTO stay_id;
-- Add stay entry to process queue for further processing -- Add stay entry to process queue for further processing
INSERT INTO process_queue (channel, payload, stored) INSERT INTO process_queue (channel, payload, stored)
@@ -527,8 +532,8 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
END IF; END IF;
-- End current log/trip -- End current log/trip
-- Fetch logbook_id by client_id -- Fetch logbook_id by vessel_id
logbook_id := public.trip_in_progress_fn(NEW.client_id::TEXT); logbook_id := public.trip_in_progress_fn(current_setting('vessel.id', true)::TEXT);
IF logbook_id IS NOT NULL THEN IF logbook_id IS NOT NULL THEN
-- todo check on time start vs end -- todo check on time start vs end
RAISE WARNING 'Metrics Updating logbook status [%] [%] [%]', logbook_id, NEW.status, NEW.time; RAISE WARNING 'Metrics Updating logbook status [%] [%] [%]', logbook_id, NEW.status, NEW.time;
@@ -628,7 +633,7 @@ CREATE FUNCTION api.export_logbook_geojson_fn(IN _id integer, OUT geojson JSON)
SELECT * INTO logbook_rec SELECT * INTO logbook_rec
FROM api.logbook WHERE id = _id; FROM api.logbook WHERE id = _id;
-- Ensure the query is successful -- Ensure the query is successful
IF logbook_rec.client_id IS NULL THEN IF logbook_rec.vessel_id IS NULL THEN
RAISE WARNING '-> export_logbook_geojson_fn invalid logbook %', _id; RAISE WARNING '-> export_logbook_geojson_fn invalid logbook %', _id;
RETURN; RETURN;
END IF; END IF;
@@ -660,7 +665,7 @@ AS $export_logbook_gpx$
api.logbook l api.logbook l
WHERE l.id = _id; WHERE l.id = _id;
-- Ensure the query is successful -- Ensure the query is successful
IF log_rec.client_id IS NULL THEN IF log_rec.vessel_id IS NULL THEN
RAISE WARNING '-> export_logbook_gpx_fn invalid logbook %', _id; RAISE WARNING '-> export_logbook_gpx_fn invalid logbook %', _id;
RETURN ''; RETURN '';
END IF; END IF;
@@ -696,7 +701,7 @@ AS $export_logbook_gpx$
AND m.longitude 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._from_time::TIMESTAMP WITHOUT TIME ZONE
AND m.time <= log_rec._to_time::TIMESTAMP WITHOUT TIME ZONE AND m.time <= log_rec._to_time::TIMESTAMP WITHOUT TIME ZONE
AND client_id = log_rec.client_id; AND vessel_id = log_rec.vessel_id;
-- ERROR: column "m.time" must appear in the GROUP BY clause or be used in an aggregate function at character 2304 -- ERROR: column "m.time" must appear in the GROUP BY clause or be used in an aggregate function at character 2304
--ORDER BY m.time ASC; --ORDER BY m.time ASC;
END; END;
@@ -808,14 +813,14 @@ COMMENT ON FUNCTION
-- trip_in_progress_fn -- trip_in_progress_fn
DROP FUNCTION IF EXISTS public.trip_in_progress_fn; DROP FUNCTION IF EXISTS public.trip_in_progress_fn;
CREATE FUNCTION public.trip_in_progress_fn(IN _client_id TEXT) RETURNS INT AS $trip_in_progress$ CREATE FUNCTION public.trip_in_progress_fn(IN _vessel_id TEXT) RETURNS INT AS $trip_in_progress$
DECLARE DECLARE
logbook_id INT := NULL; logbook_id INT := NULL;
BEGIN BEGIN
SELECT id INTO logbook_id SELECT id INTO logbook_id
FROM api.logbook l FROM api.logbook l
WHERE l.client_id IS NOT NULL WHERE l.vessel_id IS NOT NULL
AND l.client_id = _client_id AND l.vessel_id = _vessel_id
AND active IS true AND active IS true
LIMIT 1; LIMIT 1;
RETURN logbook_id; RETURN logbook_id;
@@ -828,14 +833,14 @@ COMMENT ON FUNCTION
-- stay_in_progress_fn -- stay_in_progress_fn
DROP FUNCTION IF EXISTS public.stay_in_progress_fn; DROP FUNCTION IF EXISTS public.stay_in_progress_fn;
CREATE FUNCTION public.stay_in_progress_fn(IN _client_id TEXT) RETURNS INT AS $stay_in_progress$ CREATE FUNCTION public.stay_in_progress_fn(IN _vessel_id TEXT) RETURNS INT AS $stay_in_progress$
DECLARE DECLARE
stay_id INT := NULL; stay_id INT := NULL;
BEGIN BEGIN
SELECT id INTO stay_id SELECT id INTO stay_id
FROM api.stays s FROM api.stays s
WHERE s.client_id IS NOT NULL WHERE s.vessel_id IS NOT NULL
AND s.client_id = _client_id AND s.vessel_id = _vessel_id
AND active IS true AND active IS true
LIMIT 1; LIMIT 1;
RETURN stay_id; RETURN stay_id;

View File

@@ -124,21 +124,21 @@ begin
active = False active = False
WHERE id = metadata_rec.id; WHERE id = metadata_rec.id;
IF metadata_rec.client_id IS NULL OR metadata_rec.client_id = '' THEN IF metadata_rec.vessel_id IS NULL OR metadata_rec.vessel_id = '' THEN
RAISE WARNING '-> cron_process_monitor_offline_fn invalid metadata record client_id %', client_id; RAISE WARNING '-> cron_process_monitor_offline_fn invalid metadata record vessel_id %', vessel_id;
RAISE EXCEPTION 'Invalid metadata' RAISE EXCEPTION 'Invalid metadata'
USING HINT = 'Unknow client_id'; USING HINT = 'Unknow vessel_id';
RETURN; RETURN;
END IF; END IF;
PERFORM set_config('vessel.client_id', metadata_rec.client_id, false); PERFORM set_config('vessel.id', metadata_rec.vessel_id, false);
RAISE DEBUG '-> DEBUG cron_process_monitor_offline_fn vessel.client_id %', current_setting('vessel.client_id', false); RAISE DEBUG '-> DEBUG cron_process_monitor_offline_fn vessel.id %', current_setting('vessel.id', false);
RAISE NOTICE '-> cron_process_monitor_offline_fn updated api.metadata table to inactive for [%] [%]', metadata_rec.id, metadata_rec.client_id; RAISE NOTICE '-> cron_process_monitor_offline_fn updated api.metadata table to inactive for [%] [%]', metadata_rec.id, metadata_rec.vessel_id;
-- Gather email and pushover app settings -- Gather email and pushover app settings
--app_settings = get_app_settings_fn(); --app_settings = get_app_settings_fn();
-- Gather user settings -- Gather user settings
user_settings := get_user_settings_from_clientid_fn(metadata_rec.client_id::TEXT); user_settings := get_user_settings_from_vesselid_fn(metadata_rec.vessel_id::TEXT);
RAISE DEBUG '-> cron_process_monitor_offline_fn get_user_settings_from_clientid_fn [%]', user_settings; RAISE DEBUG '-> cron_process_monitor_offline_fn get_user_settings_from_vesselid_fn [%]', user_settings;
-- Send notification -- Send notification
PERFORM send_notification_fn('monitor_offline'::TEXT, user_settings::JSONB); PERFORM send_notification_fn('monitor_offline'::TEXT, user_settings::JSONB);
--PERFORM send_email_py_fn('monitor_offline'::TEXT, user_settings::JSONB, app_settings::JSONB); --PERFORM send_email_py_fn('monitor_offline'::TEXT, user_settings::JSONB, app_settings::JSONB);
@@ -179,20 +179,20 @@ begin
FROM api.metadata FROM api.metadata
WHERE id = process_rec.payload::INTEGER; WHERE id = process_rec.payload::INTEGER;
IF metadata_rec.client_id IS NULL OR metadata_rec.client_id = '' THEN IF metadata_rec.vessel_id IS NULL OR metadata_rec.vessel_id = '' THEN
RAISE WARNING '-> cron_process_monitor_online_fn invalid metadata record client_id %', client_id; RAISE WARNING '-> cron_process_monitor_online_fn invalid metadata record vessel_id %', vessel_id;
RAISE EXCEPTION 'Invalid metadata' RAISE EXCEPTION 'Invalid metadata'
USING HINT = 'Unknow client_id'; USING HINT = 'Unknow vessel_id';
RETURN; RETURN;
END IF; END IF;
PERFORM set_config('vessel.client_id', metadata_rec.client_id, false); PERFORM set_config('vessel.id', metadata_rec.vessel_id, false);
RAISE DEBUG '-> DEBUG cron_process_monitor_online_fn vessel.client_id %', current_setting('vessel.client_id', false); RAISE DEBUG '-> DEBUG cron_process_monitor_online_fn vessel_id %', current_setting('vessel.id', false);
-- Gather email and pushover app settings -- Gather email and pushover app settings
--app_settings = get_app_settings_fn(); --app_settings = get_app_settings_fn();
-- Gather user settings -- Gather user settings
user_settings := get_user_settings_from_clientid_fn(metadata_rec.client_id::TEXT); user_settings := get_user_settings_from_vesselid_fn(metadata_rec.vessel_id::TEXT);
RAISE DEBUG '-> DEBUG cron_process_monitor_online_fn get_user_settings_from_clientid_fn [%]', user_settings; RAISE DEBUG '-> DEBUG cron_process_monitor_online_fn get_user_settings_from_vesselid_fn [%]', user_settings;
-- Send notification -- Send notification
PERFORM send_notification_fn('monitor_online'::TEXT, user_settings::JSONB); PERFORM send_notification_fn('monitor_online'::TEXT, user_settings::JSONB);
--PERFORM send_email_py_fn('monitor_online'::TEXT, user_settings::JSONB, app_settings::JSONB); --PERFORM send_email_py_fn('monitor_online'::TEXT, user_settings::JSONB, app_settings::JSONB);

View File

@@ -29,7 +29,7 @@ CREATE OR REPLACE FUNCTION logbook_metrics_dwithin_fn(
AND m.longitude IS NOT NULL AND m.longitude IS NOT NULL
AND m.time >= _start::TIMESTAMP WITHOUT TIME ZONE AND m.time >= _start::TIMESTAMP WITHOUT TIME ZONE
AND m.time <= _end::TIMESTAMP WITHOUT TIME ZONE AND m.time <= _end::TIMESTAMP WITHOUT TIME ZONE
AND client_id = current_setting('vessel.client_id', false) AND vessel_id = current_setting('vessel.id', false)
AND ST_DWithin( AND ST_DWithin(
Geography(ST_MakePoint(m.longitude, m.latitude)), Geography(ST_MakePoint(m.longitude, m.latitude)),
Geography(ST_MakePoint(lgn, lat)), Geography(ST_MakePoint(lgn, lat)),
@@ -62,7 +62,7 @@ CREATE OR REPLACE FUNCTION logbook_update_avg_fn(
AND m.longitude IS NOT NULL AND m.longitude IS NOT NULL
AND m.time >= _start::TIMESTAMP WITHOUT TIME ZONE AND m.time >= _start::TIMESTAMP WITHOUT TIME ZONE
AND m.time <= _end::TIMESTAMP WITHOUT TIME ZONE AND m.time <= _end::TIMESTAMP WITHOUT TIME ZONE
AND client_id = current_setting('vessel.client_id', false); AND vessel_id = current_setting('vessel.id', false);
RAISE NOTICE '-> Updated avg for logbook id=%, avg_speed:%, max_speed:%, max_wind_speed:%, count:%', _id, avg_speed, max_speed, max_wind_speed, count_metric; RAISE NOTICE '-> Updated avg for logbook id=%, avg_speed:%, max_speed:%, max_wind_speed:%, count:%', _id, avg_speed, max_speed, max_wind_speed, count_metric;
END; END;
$logbook_update_avg$ LANGUAGE plpgsql; $logbook_update_avg$ LANGUAGE plpgsql;
@@ -89,7 +89,7 @@ CREATE FUNCTION logbook_update_geom_distance_fn(IN _id integer, IN _start text,
AND m.longitude IS NOT NULL AND m.longitude IS NOT NULL
AND m.time >= _start::TIMESTAMP WITHOUT TIME ZONE AND m.time >= _start::TIMESTAMP WITHOUT TIME ZONE
AND m.time <= _end::TIMESTAMP WITHOUT TIME ZONE AND m.time <= _end::TIMESTAMP WITHOUT TIME ZONE
AND client_id = current_setting('vessel.client_id', false) AND vessel_id = current_setting('vessel.id', false)
ORDER BY m.time ASC ORDER BY m.time ASC
) )
) INTO _track_geom; ) INTO _track_geom;
@@ -150,7 +150,7 @@ CREATE FUNCTION logbook_update_geojson_fn(IN _id integer, IN _start text, IN _en
AND m.longitude IS NOT NULL AND m.longitude IS NOT NULL
AND time >= _start::TIMESTAMP WITHOUT TIME ZONE AND time >= _start::TIMESTAMP WITHOUT TIME ZONE
AND time <= _end::TIMESTAMP WITHOUT TIME ZONE AND time <= _end::TIMESTAMP WITHOUT TIME ZONE
AND client_id = current_setting('vessel.client_id', false) AND vessel_id = current_setting('vessel.id', false)
ORDER BY m.time ASC ORDER BY m.time ASC
) )
) AS t; ) AS t;
@@ -207,13 +207,13 @@ CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void
AND _to_lng IS NOT NULL AND _to_lng IS NOT NULL
AND _to_lat IS NOT NULL; AND _to_lat IS NOT NULL;
-- Ensure the query is successful -- Ensure the query is successful
IF logbook_rec.client_id IS NULL THEN IF logbook_rec.vessel_id IS NULL THEN
RAISE WARNING '-> process_logbook_queue_fn invalid logbook %', _id; RAISE WARNING '-> process_logbook_queue_fn invalid logbook %', _id;
RETURN; RETURN;
END IF; END IF;
PERFORM set_config('vessel.client_id', logbook_rec.client_id, false); PERFORM set_config('vessel.id', logbook_rec.vessel_id, false);
--RAISE WARNING 'public.process_logbook_queue_fn() scheduler vessel.client_id %, user.id', current_setting('vessel.client_id', false), current_setting('user.id', false); --RAISE WARNING 'public.process_logbook_queue_fn() scheduler vessel.id %, user.id', current_setting('vessel.id', false), current_setting('user.id', false);
-- Check if all metrics are within 10meters base on geo loc -- Check if all metrics are within 10meters base on geo loc
count_metric := logbook_metrics_dwithin_fn(logbook_rec._from_time::TEXT, logbook_rec._to_time::TEXT, logbook_rec._from_lng::NUMERIC, logbook_rec._from_lat::NUMERIC); count_metric := logbook_metrics_dwithin_fn(logbook_rec._from_time::TEXT, logbook_rec._to_time::TEXT, logbook_rec._from_lng::NUMERIC, logbook_rec._from_lat::NUMERIC);
@@ -240,7 +240,7 @@ CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void
SET status = 'moored' SET status = 'moored'
WHERE time >= logbook_rec._from_time::TIMESTAMP WITHOUT TIME ZONE WHERE time >= logbook_rec._from_time::TIMESTAMP WITHOUT TIME ZONE
AND time <= logbook_rec._to_time::TIMESTAMP WITHOUT TIME ZONE AND time <= logbook_rec._to_time::TIMESTAMP WITHOUT TIME ZONE
AND client_id = current_setting('vessel.client_id', false); AND vessel_id = current_setting('vessel.id', false);
-- Update logbook -- Update logbook
UPDATE api.logbook UPDATE api.logbook
SET notes = 'invalid logbook data, stationary need to fix metrics?' SET notes = 'invalid logbook data, stationary need to fix metrics?'
@@ -248,17 +248,17 @@ CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void
-- Get related stays -- Get related stays
SELECT id,departed,active INTO current_stays_id,current_stays_departed,current_stays_active SELECT id,departed,active INTO current_stays_id,current_stays_departed,current_stays_active
FROM api.stays s FROM api.stays s
WHERE s.client_id = current_setting('vessel.client_id', false) WHERE s.vessel_id = current_setting('vessel.id', false)
AND s.arrived = logbook_rec._to_time; AND s.arrived = logbook_rec._to_time;
-- Update related stays -- Update related stays
UPDATE api.stays UPDATE api.stays
SET notes = 'invalid stays data, stationary need to fix metrics?' SET notes = 'invalid stays data, stationary need to fix metrics?'
WHERE client_id = current_setting('vessel.client_id', false) WHERE vessel_id = current_setting('vessel.id', false)
AND arrived = logbook_rec._to_time; AND arrived = logbook_rec._to_time;
-- Find previous stays -- Find previous stays
SELECT id INTO previous_stays_id SELECT id INTO previous_stays_id
FROM api.stays s FROM api.stays s
WHERE s.client_id = current_setting('vessel.client_id', false) WHERE s.vessel_id = current_setting('vessel.id', false)
AND s.arrived < logbook_rec._to_time AND s.arrived < logbook_rec._to_time
ORDER BY s.arrived DESC LIMIT 1; ORDER BY s.arrived DESC LIMIT 1;
-- Update previous stays with the departed time from current stays -- Update previous stays with the departed time from current stays
@@ -266,7 +266,7 @@ CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void
UPDATE api.stays UPDATE api.stays
SET departed = current_stays_departed::timestamp without time zone, SET departed = current_stays_departed::timestamp without time zone,
active = current_stays_active active = current_stays_active
WHERE client_id = current_setting('vessel.client_id', false) WHERE vessel_id = current_setting('vessel.id', false)
AND id = previous_stays_id; AND id = previous_stays_id;
-- Clean u, remove invalid logbook and stay entry -- Clean u, remove invalid logbook and stay entry
DELETE FROM api.logbook WHERE id = logbook_rec.id; DELETE FROM api.logbook WHERE id = logbook_rec.id;
@@ -307,9 +307,9 @@ CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void
-- Prepare notification, gather user settings -- Prepare notification, gather user settings
SELECT json_build_object('logbook_name', log_name, 'logbook_link', logbook_rec.id) into log_settings; SELECT json_build_object('logbook_name', log_name, 'logbook_link', logbook_rec.id) into log_settings;
user_settings := get_user_settings_from_clientid_fn(logbook_rec.client_id::TEXT); user_settings := get_user_settings_from_vesselid_fn(logbook_rec.vessel_id::TEXT);
SELECT user_settings::JSONB || log_settings::JSONB into user_settings; SELECT user_settings::JSONB || log_settings::JSONB into user_settings;
RAISE DEBUG '-> debug process_logbook_queue_fn get_user_settings_from_clientid_fn [%]', user_settings; RAISE DEBUG '-> debug process_logbook_queue_fn get_user_settings_from_vesselid_fn [%]', user_settings;
RAISE DEBUG '-> debug process_logbook_queue_fn log_settings [%]', log_settings; RAISE DEBUG '-> debug process_logbook_queue_fn log_settings [%]', log_settings;
-- Send notification -- Send notification
PERFORM send_notification_fn('logbook'::TEXT, user_settings::JSONB); PERFORM send_notification_fn('logbook'::TEXT, user_settings::JSONB);
@@ -345,12 +345,12 @@ CREATE OR REPLACE FUNCTION process_stay_queue_fn(IN _id integer) RETURNS void AS
AND longitude IS NOT NULL AND longitude IS NOT NULL
AND latitude IS NOT NULL; AND latitude IS NOT NULL;
-- Ensure the query is successful -- Ensure the query is successful
IF stay_rec.client_id IS NULL THEN IF stay_rec.vessel_id IS NULL THEN
RAISE WARNING '-> process_stay_queue_fn invalid stay %', _id; RAISE WARNING '-> process_stay_queue_fn invalid stay %', _id;
RETURN; RETURN;
END IF; END IF;
PERFORM set_config('vessel.client_id', stay_rec.client_id, false); PERFORM set_config('vessel.id', stay_rec.vessel_id, false);
-- geo reverse _lng _lat -- geo reverse _lng _lat
_name := reverse_geocode_py_fn('nominatim', stay_rec.longitude::NUMERIC, stay_rec.latitude::NUMERIC); _name := reverse_geocode_py_fn('nominatim', stay_rec.longitude::NUMERIC, stay_rec.latitude::NUMERIC);
@@ -395,12 +395,12 @@ CREATE OR REPLACE FUNCTION process_moorage_queue_fn(IN _id integer) RETURNS void
AND latitude IS NOT NULL AND latitude IS NOT NULL
AND id = _id; AND id = _id;
-- Ensure the query is successful -- Ensure the query is successful
IF stay_rec.client_id IS NULL THEN IF stay_rec.vessel_id IS NULL THEN
RAISE WARNING '-> process_moorage_queue_fn invalid stay %', _id; RAISE WARNING '-> process_moorage_queue_fn invalid stay %', _id;
RETURN; RETURN;
END IF; END IF;
PERFORM set_config('vessel.client_id', stay_rec.client_id, false); PERFORM set_config('vessel.id', stay_rec.vessel_id, false);
-- Do we have an existing stay within 100m of the new moorage -- Do we have an existing stay within 100m of the new moorage
FOR moorage_rec in FOR moorage_rec in
@@ -446,9 +446,9 @@ CREATE OR REPLACE FUNCTION process_moorage_queue_fn(IN _id integer) RETURNS void
END IF; END IF;
-- Insert new moorage from stay -- Insert new moorage from stay
INSERT INTO api.moorages INSERT INTO api.moorages
(client_id, name, stay_id, stay_code, stay_duration, reference_count, latitude, longitude, geog) (vessel_id, name, stay_id, stay_code, stay_duration, reference_count, latitude, longitude, geog)
VALUES ( VALUES (
stay_rec.client_id, stay_rec.vessel_id,
stay_rec.name, stay_rec.name,
stay_rec.id, stay_rec.id,
stay_rec.stay_code, stay_rec.stay_code,
@@ -627,7 +627,7 @@ CREATE OR REPLACE FUNCTION process_vessel_queue_fn(IN _email TEXT) RETURNS void
PERFORM set_config('user.email', vessel_rec.owner_email, false); PERFORM set_config('user.email', vessel_rec.owner_email, false);
-- Gather user settings -- Gather user settings
user_settings := '{"email": "' || vessel_rec.owner_email || '", "boat": "' || vessel_rec.name || '"}'; user_settings := '{"email": "' || vessel_rec.owner_email || '", "boat": "' || vessel_rec.name || '"}';
--user_settings := get_user_settings_from_clientid_fn(); --user_settings := get_user_settings_from_vesselid_fn();
-- Send notification email, pushover -- Send notification email, pushover
--PERFORM send_notification_fn('vessel'::TEXT, vessel_rec::RECORD); --PERFORM send_notification_fn('vessel'::TEXT, vessel_rec::RECORD);
PERFORM send_email_py_fn('new_vessel'::TEXT, user_settings::JSONB, app_settings::JSONB); PERFORM send_email_py_fn('new_vessel'::TEXT, user_settings::JSONB, app_settings::JSONB);
@@ -730,17 +730,17 @@ COMMENT ON FUNCTION
public.send_notification_fn public.send_notification_fn
IS 'Send notifications via email, pushover, telegram to user base on user preferences'; IS 'Send notifications via email, pushover, telegram to user base on user preferences';
DROP FUNCTION IF EXISTS get_user_settings_from_clientid_fn; DROP FUNCTION IF EXISTS get_user_settings_from_vesselid_fn;
CREATE OR REPLACE FUNCTION get_user_settings_from_clientid_fn( CREATE OR REPLACE FUNCTION get_user_settings_from_vesselid_fn(
IN clientid TEXT, IN vesselid TEXT,
OUT user_settings JSONB OUT user_settings JSONB
) RETURNS JSONB ) RETURNS JSONB
AS $get_user_settings_from_clientid$ AS $get_user_settings_from_vesselid$
DECLARE DECLARE
BEGIN BEGIN
-- If client_id is not NULL -- If vessel_id is not NULL
IF clientid IS NULL OR clientid = '' THEN IF vesselid IS NULL OR vesselid = '' THEN
RAISE WARNING '-> get_user_settings_from_clientid_fn invalid input %', clientid; RAISE WARNING '-> get_user_settings_from_vesselid_fn invalid input %', vesselid;
END IF; END IF;
SELECT SELECT
json_build_object( json_build_object(
@@ -753,16 +753,16 @@ AS $get_user_settings_from_clientid$
) INTO user_settings ) INTO user_settings
FROM auth.accounts a, auth.vessels v, api.metadata m FROM auth.accounts a, auth.vessels v, api.metadata m
WHERE m.vessel_id = v.vessel_id WHERE m.vessel_id = v.vessel_id
AND m.client_id = clientid AND m.vessel_id = vesselid
AND lower(a.email) = lower(v.owner_email); AND lower(a.email) = lower(v.owner_email);
PERFORM set_config('user.email', user_settings->>'email'::TEXT, false); PERFORM set_config('user.email', user_settings->>'email'::TEXT, false);
PERFORM set_config('user.recipient', user_settings->>'recipient'::TEXT, false); PERFORM set_config('user.recipient', user_settings->>'recipient'::TEXT, false);
END; END;
$get_user_settings_from_clientid$ LANGUAGE plpgsql; $get_user_settings_from_vesselid$ LANGUAGE plpgsql;
-- Description -- Description
COMMENT ON FUNCTION COMMENT ON FUNCTION
public.get_user_settings_from_clientid_fn public.get_user_settings_from_vesselid_fn
IS 'get user settings details from a clientid, initiate for notifications'; IS 'get user settings details from a vesselid initiate for notifications';
DROP FUNCTION IF EXISTS set_vessel_settings_from_vesselid_fn; DROP FUNCTION IF EXISTS set_vessel_settings_from_vesselid_fn;
CREATE OR REPLACE FUNCTION set_vessel_settings_from_vesselid_fn( CREATE OR REPLACE FUNCTION set_vessel_settings_from_vesselid_fn(
@@ -772,7 +772,7 @@ CREATE OR REPLACE FUNCTION set_vessel_settings_from_vesselid_fn(
AS $set_vessel_settings_from_vesselid$ AS $set_vessel_settings_from_vesselid$
DECLARE DECLARE
BEGIN BEGIN
-- If client_id is not NULL -- If vessel_id is not NULL
IF vesselid IS NULL OR vesselid = '' THEN IF vesselid IS NULL OR vesselid = '' THEN
RAISE WARNING '-> set_vessel_settings_from_vesselid_fn invalid input %', vesselid; RAISE WARNING '-> set_vessel_settings_from_vesselid_fn invalid input %', vesselid;
END IF; END IF;
@@ -784,10 +784,10 @@ AS $set_vessel_settings_from_vesselid$
) INTO vessel_settings ) INTO vessel_settings
FROM auth.accounts a, auth.vessels v, api.metadata m FROM auth.accounts a, auth.vessels v, api.metadata m
WHERE m.vessel_id = v.vessel_id WHERE m.vessel_id = v.vessel_id
AND m.client_id = clientid; AND m.vessel_id = vesselid;
PERFORM set_config('vessel.name', vessel_settings->>'name'::TEXT, false); PERFORM set_config('vessel.name', vessel_settings->>'name'::TEXT, false);
PERFORM set_config('vessel.client_id', vessel_settings->>'client_id'::TEXT, false); PERFORM set_config('vessel.client_id', vessel_settings->>'client_id'::TEXT, false);
PERFORM set_config('vessel.vessel_id', vessel_settings->>'vessel_id'::TEXT, false); PERFORM set_config('vessel.id', vessel_settings->>'vessel_id'::TEXT, false);
END; END;
$set_vessel_settings_from_vesselid$ LANGUAGE plpgsql; $set_vessel_settings_from_vesselid$ LANGUAGE plpgsql;
-- Description -- Description
@@ -813,7 +813,7 @@ CREATE OR REPLACE FUNCTION public.badges_logbook_fn(IN logbook_id integer) RETUR
SELECT (preferences->'badges'->'Helmsman') IS NOT NULL INTO _exist FROM auth.accounts a WHERE a.email = current_setting('user.email', false); SELECT (preferences->'badges'->'Helmsman') IS NOT NULL INTO _exist FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
if _exist is false THEN if _exist is false THEN
-- is first logbook? -- is first logbook?
select count(*) into total from api.logbook l where client_id = current_setting('vessel.client_id', false); select count(*) into total from api.logbook l where vessel_id = current_setting('vessel.id', false);
if total >= 1 then if total >= 1 then
-- Add badge -- Add badge
badge := '{"Helmsman": {"log": '|| logbook_id ||', "date":"' || NOW()::timestamp || '"}}'; badge := '{"Helmsman": {"log": '|| logbook_id ||', "date":"' || NOW()::timestamp || '"}}';
@@ -824,7 +824,7 @@ CREATE OR REPLACE FUNCTION public.badges_logbook_fn(IN logbook_id integer) RETUR
-- Update badges -- Update badges
PERFORM api.update_user_preferences_fn('{badges}'::TEXT, badge::TEXT); PERFORM api.update_user_preferences_fn('{badges}'::TEXT, badge::TEXT);
-- Gather user settings -- Gather user settings
user_settings := get_user_settings_from_clientid_fn(current_setting('vessel.client_id', false)); user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
SELECT user_settings::JSONB || '{"badge": "Helmsman"}'::JSONB into user_settings; SELECT user_settings::JSONB || '{"badge": "Helmsman"}'::JSONB into user_settings;
-- Send notification -- Send notification
PERFORM send_notification_fn('new_badge'::TEXT, user_settings::JSONB); PERFORM send_notification_fn('new_badge'::TEXT, user_settings::JSONB);
@@ -836,7 +836,7 @@ CREATE OR REPLACE FUNCTION public.badges_logbook_fn(IN logbook_id integer) RETUR
RAISE WARNING '-> Wake Maker %', _exist; RAISE WARNING '-> Wake Maker %', _exist;
if _exist is false then if _exist is false then
-- is 15 knot+ logbook? -- is 15 knot+ logbook?
select l.max_wind_speed into max_wind_speed from api.logbook l where l.id = logbook_id AND l.max_wind_speed >= 15 and client_id = current_setting('vessel.client_id', false); select l.max_wind_speed into max_wind_speed from api.logbook l where l.id = logbook_id AND l.max_wind_speed >= 15 and vessel_id = current_setting('vessel.id', false);
--RAISE WARNING '-> Wake Maker max_wind_speed %', max_wind_speed; --RAISE WARNING '-> Wake Maker max_wind_speed %', max_wind_speed;
if max_wind_speed >= 15 then if max_wind_speed >= 15 then
-- Create badge -- Create badge
@@ -850,7 +850,7 @@ CREATE OR REPLACE FUNCTION public.badges_logbook_fn(IN logbook_id integer) RETUR
-- Update badges for user -- Update badges for user
PERFORM api.update_user_preferences_fn('{badges}'::TEXT, badge::TEXT); PERFORM api.update_user_preferences_fn('{badges}'::TEXT, badge::TEXT);
-- Gather user settings -- Gather user settings
user_settings := get_user_settings_from_clientid_fn(current_setting('vessel.client_id', false)); user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
SELECT user_settings::JSONB || '{"badge": "Wake Maker"}'::JSONB into user_settings; SELECT user_settings::JSONB || '{"badge": "Wake Maker"}'::JSONB into user_settings;
-- Send notification -- Send notification
PERFORM send_notification_fn('new_badge'::TEXT, user_settings::JSONB); PERFORM send_notification_fn('new_badge'::TEXT, user_settings::JSONB);
@@ -861,7 +861,7 @@ CREATE OR REPLACE FUNCTION public.badges_logbook_fn(IN logbook_id integer) RETUR
SELECT (preferences->'badges'->'Stormtrooper') IS NOT NULL INTO _exist FROM auth.accounts a WHERE a.email = current_setting('user.email', false); SELECT (preferences->'badges'->'Stormtrooper') IS NOT NULL INTO _exist FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
if _exist is false then if _exist is false then
--RAISE WARNING '-> Stormtrooper %', _exist; --RAISE WARNING '-> Stormtrooper %', _exist;
select l.max_wind_speed into max_wind_speed from api.logbook l where l.id = logbook_id AND l.max_wind_speed >= 30 and client_id = current_setting('vessel.client_id', false); select l.max_wind_speed into max_wind_speed from api.logbook l where l.id = logbook_id AND l.max_wind_speed >= 30 and vessel_id = current_setting('vessel.id', false);
--RAISE WARNING '-> Stormtrooper max_wind_speed %', max_wind_speed; --RAISE WARNING '-> Stormtrooper max_wind_speed %', max_wind_speed;
if max_wind_speed >= 30 then if max_wind_speed >= 30 then
-- Create badge -- Create badge
@@ -875,7 +875,7 @@ CREATE OR REPLACE FUNCTION public.badges_logbook_fn(IN logbook_id integer) RETUR
-- Update badges for user -- Update badges for user
PERFORM api.update_user_preferences_fn('{badges}'::TEXT, badge::TEXT); PERFORM api.update_user_preferences_fn('{badges}'::TEXT, badge::TEXT);
-- Gather user settings -- Gather user settings
user_settings := get_user_settings_from_clientid_fn(current_setting('vessel.client_id', false)); user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
SELECT user_settings::JSONB || '{"badge": "Stormtrooper"}'::JSONB into user_settings; SELECT user_settings::JSONB || '{"badge": "Stormtrooper"}'::JSONB into user_settings;
-- Send notification -- Send notification
PERFORM send_notification_fn('new_badge'::TEXT, user_settings::JSONB); PERFORM send_notification_fn('new_badge'::TEXT, user_settings::JSONB);
@@ -885,7 +885,7 @@ CREATE OR REPLACE FUNCTION public.badges_logbook_fn(IN logbook_id integer) RETUR
-- Navigator Award = one logbook with distance over 100NM -- Navigator Award = one logbook with distance over 100NM
SELECT (preferences->'badges'->'Navigator Award') IS NOT NULL INTO _exist FROM auth.accounts a WHERE a.email = current_setting('user.email', false); SELECT (preferences->'badges'->'Navigator Award') IS NOT NULL INTO _exist FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
if _exist is false then if _exist is false then
select l.distance into distance from api.logbook l where l.id = logbook_id AND l.distance >= 100 and client_id = current_setting('vessel.client_id', false); select l.distance into distance from api.logbook l where l.id = logbook_id AND l.distance >= 100 and vessel_id = current_setting('vessel.id', false);
if distance >= 100 then if distance >= 100 then
-- Create badge -- Create badge
badge := '{"Navigator Award": {"log": '|| logbook_id ||', "date":"' || NOW()::timestamp || '"}}'; badge := '{"Navigator Award": {"log": '|| logbook_id ||', "date":"' || NOW()::timestamp || '"}}';
@@ -896,7 +896,7 @@ CREATE OR REPLACE FUNCTION public.badges_logbook_fn(IN logbook_id integer) RETUR
-- Update badges for user -- Update badges for user
PERFORM api.update_user_preferences_fn('{badges}'::TEXT, badge::TEXT); PERFORM api.update_user_preferences_fn('{badges}'::TEXT, badge::TEXT);
-- Gather user settings -- Gather user settings
user_settings := get_user_settings_from_clientid_fn(current_setting('vessel.client_id', false)); user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
SELECT user_settings::JSONB || '{"badge": "Navigator Award"}'::JSONB into user_settings; SELECT user_settings::JSONB || '{"badge": "Navigator Award"}'::JSONB into user_settings;
-- Send notification -- Send notification
PERFORM send_notification_fn('new_badge'::TEXT, user_settings::JSONB); PERFORM send_notification_fn('new_badge'::TEXT, user_settings::JSONB);
@@ -906,7 +906,7 @@ CREATE OR REPLACE FUNCTION public.badges_logbook_fn(IN logbook_id integer) RETUR
-- Captain Award = total logbook distance over 1000NM -- Captain Award = total logbook distance over 1000NM
SELECT (preferences->'badges'->'Captain Award') IS NOT NULL INTO _exist FROM auth.accounts a WHERE a.email = current_setting('user.email', false); SELECT (preferences->'badges'->'Captain Award') IS NOT NULL INTO _exist FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
if _exist is false then if _exist is false then
select sum(l.distance) into distance from api.logbook l where client_id = current_setting('vessel.client_id', false); select sum(l.distance) into distance from api.logbook l where vessel_id = current_setting('vessel.id', false);
if distance >= 1000 then if distance >= 1000 then
-- Create badge -- Create badge
badge := '{"Captain Award": {"log": '|| logbook_id ||', "date":"' || NOW()::timestamp || '"}}'; badge := '{"Captain Award": {"log": '|| logbook_id ||', "date":"' || NOW()::timestamp || '"}}';
@@ -917,7 +917,7 @@ CREATE OR REPLACE FUNCTION public.badges_logbook_fn(IN logbook_id integer) RETUR
-- Update badges for user -- Update badges for user
PERFORM api.update_user_preferences_fn('{badges}'::TEXT, badge::TEXT); PERFORM api.update_user_preferences_fn('{badges}'::TEXT, badge::TEXT);
-- Gather user settings -- Gather user settings
user_settings := get_user_settings_from_clientid_fn(current_setting('vessel.client_id', false)); user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
SELECT user_settings::JSONB || '{"badge": "Captain Award"}'::JSONB into user_settings; SELECT user_settings::JSONB || '{"badge": "Captain Award"}'::JSONB into user_settings;
-- Send notification -- Send notification
PERFORM send_notification_fn('new_badge'::TEXT, user_settings::JSONB); PERFORM send_notification_fn('new_badge'::TEXT, user_settings::JSONB);
@@ -940,14 +940,14 @@ CREATE OR REPLACE FUNCTION public.badges_moorages_fn() RETURNS VOID AS $badges_m
user_settings jsonb; user_settings jsonb;
BEGIN BEGIN
-- Check and set environment -- Check and set environment
user_settings := get_user_settings_from_clientid_fn(current_setting('vessel.client_id', false)); user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
PERFORM set_config('user.email', user_settings->>'email'::TEXT, false); PERFORM set_config('user.email', user_settings->>'email'::TEXT, false);
-- Explorer = 10 days away from home port -- Explorer = 10 days away from home port
SELECT (preferences->'badges'->'Explorer') IS NOT NULL INTO _exist FROM auth.accounts a WHERE a.email = current_setting('user.email', false); SELECT (preferences->'badges'->'Explorer') IS NOT NULL INTO _exist FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
if _exist is false then if _exist is false then
--select sum(m.stay_duration) from api.moorages m where home_flag is false; --select sum(m.stay_duration) from api.moorages m where home_flag is false;
SELECT extract(day from (select sum(m.stay_duration) INTO duration FROM api.moorages m WHERE home_flag IS false AND client_id = current_setting('vessel.client_id', false) )); SELECT extract(day from (select sum(m.stay_duration) INTO duration FROM api.moorages m WHERE home_flag IS false AND vessel_id = current_setting('vessel.id', false) ));
if duration >= 10 then if duration >= 10 then
-- Create badge -- Create badge
badge := '{"Explorer": {"date":"' || NOW()::timestamp || '"}}'; badge := '{"Explorer": {"date":"' || NOW()::timestamp || '"}}';
@@ -958,7 +958,7 @@ CREATE OR REPLACE FUNCTION public.badges_moorages_fn() RETURNS VOID AS $badges_m
-- Update badges for user -- Update badges for user
PERFORM api.update_user_preferences_fn('{badges}'::TEXT, badge::TEXT); PERFORM api.update_user_preferences_fn('{badges}'::TEXT, badge::TEXT);
-- Gather user settings -- Gather user settings
user_settings := get_user_settings_from_clientid_fn(current_setting('vessel.client_id', false)); user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
SELECT user_settings::JSONB || '{"badge": "Explorer"}'::JSONB into user_settings; SELECT user_settings::JSONB || '{"badge": "Explorer"}'::JSONB into user_settings;
-- Send notification -- Send notification
PERFORM send_notification_fn('new_badge'::TEXT, user_settings::JSONB); PERFORM send_notification_fn('new_badge'::TEXT, user_settings::JSONB);
@@ -969,7 +969,7 @@ CREATE OR REPLACE FUNCTION public.badges_moorages_fn() RETURNS VOID AS $badges_m
SELECT (preferences->'badges'->'Mooring Pro') IS NOT NULL INTO _exist FROM auth.accounts a WHERE a.email = current_setting('user.email', false); SELECT (preferences->'badges'->'Mooring Pro') IS NOT NULL INTO _exist FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
if _exist is false then if _exist is false then
-- select sum(m.stay_duration) from api.moorages m where stay_code = 3; -- select sum(m.stay_duration) from api.moorages m where stay_code = 3;
SELECT extract(day from (select sum(m.stay_duration) INTO duration FROM api.moorages m WHERE stay_code = 3 AND client_id = current_setting('vessel.client_id', false) )); SELECT extract(day from (select sum(m.stay_duration) INTO duration FROM api.moorages m WHERE stay_code = 3 AND vessel_id = current_setting('vessel.id', false) ));
if duration >= 10 then if duration >= 10 then
-- Create badge -- Create badge
badge := '{"Mooring Pro": {"date":"' || NOW()::timestamp || '"}}'; badge := '{"Mooring Pro": {"date":"' || NOW()::timestamp || '"}}';
@@ -980,7 +980,7 @@ CREATE OR REPLACE FUNCTION public.badges_moorages_fn() RETURNS VOID AS $badges_m
-- Update badges for user -- Update badges for user
PERFORM api.update_user_preferences_fn('{badges}'::TEXT, badge::TEXT); PERFORM api.update_user_preferences_fn('{badges}'::TEXT, badge::TEXT);
-- Gather user settings -- Gather user settings
user_settings := get_user_settings_from_clientid_fn(current_setting('vessel.client_id', false)); user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
SELECT user_settings::JSONB || '{"badge": "Mooring Pro"}'::JSONB into user_settings; SELECT user_settings::JSONB || '{"badge": "Mooring Pro"}'::JSONB into user_settings;
-- Send notification -- Send notification
PERFORM send_notification_fn('new_badge'::TEXT, user_settings::JSONB); PERFORM send_notification_fn('new_badge'::TEXT, user_settings::JSONB);
@@ -991,7 +991,7 @@ CREATE OR REPLACE FUNCTION public.badges_moorages_fn() RETURNS VOID AS $badges_m
SELECT (preferences->'badges'->'Anchormaster') IS NOT NULL INTO _exist FROM auth.accounts a WHERE a.email = current_setting('user.email', false); SELECT (preferences->'badges'->'Anchormaster') IS NOT NULL INTO _exist FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
if _exist is false then if _exist is false then
-- select sum(m.stay_duration) from api.moorages m where stay_code = 2; -- select sum(m.stay_duration) from api.moorages m where stay_code = 2;
SELECT extract(day from (select sum(m.stay_duration) INTO duration FROM api.moorages m WHERE stay_code = 2 AND client_id = current_setting('vessel.client_id', false) )); SELECT extract(day from (select sum(m.stay_duration) INTO duration FROM api.moorages m WHERE stay_code = 2 AND vessel_id = current_setting('vessel.id', false) ));
if duration >= 25 then if duration >= 25 then
-- Create badge -- Create badge
badge := '{"Anchormaster": {"date":"' || NOW()::timestamp || '"}}'; badge := '{"Anchormaster": {"date":"' || NOW()::timestamp || '"}}';
@@ -1002,7 +1002,7 @@ CREATE OR REPLACE FUNCTION public.badges_moorages_fn() RETURNS VOID AS $badges_m
-- Update badges for user -- Update badges for user
PERFORM api.update_user_preferences_fn('{badges}'::TEXT, badge::TEXT); PERFORM api.update_user_preferences_fn('{badges}'::TEXT, badge::TEXT);
-- Gather user settings -- Gather user settings
user_settings := get_user_settings_from_clientid_fn(current_setting('vessel.client_id', false)); user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
SELECT user_settings::JSONB || '{"badge": "Anchormaster"}'::JSONB into user_settings; SELECT user_settings::JSONB || '{"badge": "Anchormaster"}'::JSONB into user_settings;
-- Send notification -- Send notification
PERFORM send_notification_fn('new_badge'::TEXT, user_settings::JSONB); PERFORM send_notification_fn('new_badge'::TEXT, user_settings::JSONB);
@@ -1025,13 +1025,13 @@ CREATE OR REPLACE FUNCTION public.badges_geom_fn(IN logbook_id integer) RETURNS
user_settings jsonb; user_settings jsonb;
badge_tmp text; badge_tmp text;
begin begin
RAISE WARNING '--> user.email [%], vessel.client_id [%]', current_setting('user.email', false), current_setting('vessel.client_id', false); RAISE WARNING '--> user.email [%], vessel.id [%]', current_setting('user.email', false), current_setting('vessel.id', false);
-- Tropical & Alaska zone manualy add into ne_10m_geography_marine_polys -- Tropical & Alaska zone manualy add into ne_10m_geography_marine_polys
-- Check if each geographic marine zone exist as a badge -- Check if each geographic marine zone exist as a badge
FOR marine_rec IN FOR marine_rec IN
WITH log AS ( WITH log AS (
SELECT l.track_geom AS track_geom FROM api.logbook l SELECT l.track_geom AS track_geom FROM api.logbook l
WHERE l.id = logbook_id AND client_id = current_setting('vessel.client_id', false) WHERE l.id = logbook_id AND vessel_id = current_setting('vessel.id', false)
) )
SELECT name from log, public.ne_10m_geography_marine_polys SELECT name from log, public.ne_10m_geography_marine_polys
WHERE ST_Intersects( WHERE ST_Intersects(
@@ -1055,7 +1055,7 @@ CREATE OR REPLACE FUNCTION public.badges_geom_fn(IN logbook_id integer) RETURNS
--RAISE WARNING '--> badges_geom_fn [%]', badge; --RAISE WARNING '--> badges_geom_fn [%]', badge;
-- Gather user settings -- Gather user settings
badge_tmp := '{"badge": "' || marine_rec.name || '"}'; badge_tmp := '{"badge": "' || marine_rec.name || '"}';
user_settings := get_user_settings_from_clientid_fn(current_setting('vessel.client_id', false)); user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
SELECT user_settings::JSONB || badge_tmp::JSONB INTO user_settings; SELECT user_settings::JSONB || badge_tmp::JSONB INTO user_settings;
-- Send notification -- Send notification
PERFORM send_notification_fn('new_badge'::TEXT, user_settings::JSONB); PERFORM send_notification_fn('new_badge'::TEXT, user_settings::JSONB);
@@ -1150,7 +1150,7 @@ BEGIN
AND m.vessel_id = v.vessel_id AND m.vessel_id = v.vessel_id
AND v.owner_email = _email; AND v.owner_email = _email;
-- Set session variables -- Set session variables
PERFORM set_config('vessel.client_id', _clientid, false); --PERFORM set_config('vessel.client_id', _clientid, false);
--RAISE WARNING 'public.check_jwt() user_role vessel.client_id [%]', current_setting('vessel.client_id', false); --RAISE WARNING 'public.check_jwt() user_role vessel.client_id [%]', current_setting('vessel.client_id', false);
--RAISE WARNING 'public.check_jwt() user_role vessel.id [%]', current_setting('vessel.id', false); --RAISE WARNING 'public.check_jwt() user_role vessel.id [%]', current_setting('vessel.id', false);
--RAISE WARNING 'public.check_jwt() user_role vessel.name [%]', current_setting('vessel.name', false); --RAISE WARNING 'public.check_jwt() user_role vessel.name [%]', current_setting('vessel.name', false);
@@ -1172,7 +1172,7 @@ BEGIN
--PERFORM set_config('vessel.client_id', vessel_rec.client_id, false); --PERFORM set_config('vessel.client_id', vessel_rec.client_id, false);
--RAISE WARNING 'public.check_jwt() user_role vessel.mmsi %', current_setting('vessel.mmsi', false); --RAISE WARNING 'public.check_jwt() user_role vessel.mmsi %', current_setting('vessel.mmsi', false);
--RAISE WARNING 'public.check_jwt() user_role vessel.name %', current_setting('vessel.name', false); --RAISE WARNING 'public.check_jwt() user_role vessel.name %', current_setting('vessel.name', false);
--RAISE WARNING 'public.check_jwt() user_role vessel.client_id %', current_setting('vessel.client_id', false); --RAISE WARNING 'public.check_jwt() user_role vessel.id %', current_setting('vessel.id', false);
ELSIF _role <> 'api_anonymous' THEN ELSIF _role <> 'api_anonymous' THEN
RAISE EXCEPTION 'Invalid role' RAISE EXCEPTION 'Invalid role'
USING HINT = 'Stop being so evil and maybe you can log in'; USING HINT = 'Stop being so evil and maybe you can log in';

View File

@@ -9,7 +9,8 @@ select current_database();
\c signalk \c signalk
-- Link auth.vessels with api.metadata -- Link auth.vessels with api.metadata
ALTER TABLE api.metadata ADD vessel_id TEXT NOT NULL REFERENCES auth.vessels(vessel_id) ON DELETE RESTRICT; --ALTER TABLE api.metadata ADD vessel_id TEXT NOT NULL REFERENCES auth.vessels(vessel_id) ON DELETE RESTRICT;
ALTER TABLE api.metadata ADD FOREIGN KEY (vessel_id) REFERENCES auth.vessels(vessel_id) ON DELETE RESTRICT;
COMMENT ON COLUMN api.metadata.vessel_id IS 'Link auth.vessels with api.metadata'; COMMENT ON COLUMN api.metadata.vessel_id IS 'Link auth.vessels with api.metadata';
-- Link auth.vessels with auth.accounts -- Link auth.vessels with auth.accounts
@@ -93,7 +94,7 @@ AS $vessel$
WHERE WHERE
latitude IS NOT NULL latitude IS NOT NULL
AND longitude IS NOT NULL AND longitude IS NOT NULL
AND client_id = current_setting('vessel.client_id', false) AND vessel_id = current_setting('vessel.id', false)
ORDER BY time DESC ORDER BY time DESC
) AS geojson_t ) AS geojson_t
WHERE WHERE
@@ -206,7 +207,7 @@ $vessel_details$
DECLARE DECLARE
BEGIN BEGIN
RETURN ( WITH tbl AS ( RETURN ( WITH tbl AS (
SELECT mmsi,ship_type,length,beam,height FROM api.metadata WHERE client_id = current_setting('vessel.client_id', false) SELECT mmsi,ship_type,length,beam,height FROM api.metadata WHERE vessel_id = current_setting('vessel.id', false)
) )
SELECT json_build_object( SELECT json_build_object(
'ship_type', (SELECT ais.description FROM aistypes ais, tbl WHERE t.ship_type = ais.id), 'ship_type', (SELECT ais.description FROM aistypes ais, tbl WHERE t.ship_type = ais.id),

View File

@@ -185,19 +185,19 @@ CREATE POLICY admin_all ON api.metadata TO current_user
WITH CHECK (true); WITH CHECK (true);
-- Allow vessel_role to insert and select on their own records -- Allow vessel_role to insert and select on their own records
CREATE POLICY api_vessel_role ON api.metadata TO vessel_role CREATE POLICY api_vessel_role ON api.metadata TO vessel_role
USING (client_id = current_setting('vessel.client_id', false)) USING (vessel_id = current_setting('vessel.id', false))
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 api.metadata TO user_role CREATE POLICY api_user_role ON api.metadata TO user_role
USING (client_id = current_setting('vessel.client_id', true)) USING (vessel_id = current_setting('vessel.id', true))
WITH CHECK (client_id = current_setting('vessel.client_id', false)); WITH CHECK (vessel_id = current_setting('vessel.id', false));
-- Allow scheduler to update and select based on the client_id -- Allow scheduler to update and select based on the vessel.id
CREATE POLICY api_scheduler_role ON api.metadata TO scheduler CREATE POLICY api_scheduler_role ON api.metadata TO scheduler
USING (client_id = current_setting('vessel.client_id', false)) USING (vessel_id = current_setting('vessel.id', false))
WITH CHECK (client_id = current_setting('vessel.client_id', false)); WITH CHECK (vessel_id = current_setting('vessel.id', false));
-- Allow grafana to select based on email -- Allow grafana to select based on email
CREATE POLICY grafana_role ON api.metadata TO grafana CREATE POLICY grafana_role ON api.metadata TO grafana
USING (client_id = current_setting('vessel.client_id', false)) USING (vessel_id = current_setting('vessel.id', false))
WITH CHECK (false); WITH CHECK (false);
-- Allow grafana_auth to select -- Allow grafana_auth to select
CREATE POLICY grafana_proxy_role ON api.metadata TO grafana_auth CREATE POLICY grafana_proxy_role ON api.metadata TO grafana_auth
@@ -211,19 +211,19 @@ CREATE POLICY admin_all ON api.metrics TO current_user
WITH CHECK (true); WITH CHECK (true);
-- Allow vessel_role to insert and select on their own records -- Allow vessel_role to insert and select on their own records
CREATE POLICY api_vessel_role ON api.metrics TO vessel_role CREATE POLICY api_vessel_role ON api.metrics TO vessel_role
USING (client_id = current_setting('vessel.client_id', false)) USING (vessel_id = current_setting('vessel.id', false))
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 api.metrics TO user_role CREATE POLICY api_user_role ON api.metrics TO user_role
USING (client_id = current_setting('vessel.client_id', true)) USING (vessel_id = current_setting('vessel.id', true))
WITH CHECK (client_id = current_setting('vessel.client_id', false)); WITH CHECK (vessel_id = current_setting('vessel.id', false));
-- Allow scheduler to update and select based on the client_id -- Allow scheduler to update and select based on the vessel.id
CREATE POLICY api_scheduler_role ON api.metrics TO scheduler CREATE POLICY api_scheduler_role ON api.metrics TO scheduler
USING (client_id = current_setting('vessel.client_id', false)) USING (vessel_id = current_setting('vessel.id', false))
WITH CHECK (client_id = current_setting('vessel.client_id', false)); WITH CHECK (vessel_id = current_setting('vessel.id', false));
-- Allow grafana to select based on the client_id -- Allow grafana to select based on the vessel.id
CREATE POLICY grafana_role ON api.metrics TO grafana CREATE POLICY grafana_role ON api.metrics TO grafana
USING (client_id = current_setting('vessel.client_id', false)) USING (vessel_id = current_setting('vessel.id', false))
WITH CHECK (false); WITH CHECK (false);
-- Be sure to enable row level security on the table -- Be sure to enable row level security on the table
@@ -235,19 +235,19 @@ CREATE POLICY admin_all ON api.logbook TO current_user
WITH CHECK (true); WITH CHECK (true);
-- Allow vessel_role to insert and select on their own records -- Allow vessel_role to insert and select on their own records
CREATE POLICY api_vessel_role ON api.logbook TO vessel_role CREATE POLICY api_vessel_role ON api.logbook TO vessel_role
USING (client_id = current_setting('vessel.client_id', false)) USING (vessel_id = current_setting('vessel.id', false))
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 api.logbook TO user_role CREATE POLICY api_user_role ON api.logbook TO user_role
USING (client_id = current_setting('vessel.client_id', true)) USING (vessel_id = current_setting('vessel.id', true))
WITH CHECK (client_id = current_setting('vessel.client_id', false)); WITH CHECK (vessel_id = current_setting('vessel.id', false));
-- Allow scheduler to update and select based on the client_id -- Allow scheduler to update and select based on the vessel.id
CREATE POLICY api_scheduler_role ON api.logbook TO scheduler CREATE POLICY api_scheduler_role ON api.logbook TO scheduler
USING (client_id = current_setting('vessel.client_id', false)) USING (vessel_id = current_setting('vessel.id', false))
WITH CHECK (client_id = current_setting('vessel.client_id', false)); WITH CHECK (vessel_id = current_setting('vessel.id', false));
-- Allow grafana to select based on the client_id -- Allow grafana to select based on the vessel.id
CREATE POLICY grafana_role ON api.logbook TO grafana CREATE POLICY grafana_role ON api.logbook TO grafana
USING (client_id = current_setting('vessel.client_id', false)) USING (vessel_id = current_setting('vessel.id', false))
WITH CHECK (false); WITH CHECK (false);
-- Be sure to enable row level security on the table -- Be sure to enable row level security on the table
@@ -258,19 +258,19 @@ CREATE POLICY admin_all ON api.stays TO current_user
WITH CHECK (true); WITH CHECK (true);
-- Allow vessel_role to insert and select on their own records -- Allow vessel_role to insert and select on their own records
CREATE POLICY api_vessel_role ON api.stays TO vessel_role CREATE POLICY api_vessel_role ON api.stays TO vessel_role
USING (client_id = current_setting('vessel.client_id', false)) USING (vessel_id = current_setting('vessel.id', false))
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 api.stays TO user_role CREATE POLICY api_user_role ON api.stays TO user_role
USING (client_id = current_setting('vessel.client_id', true)) USING (vessel_id = current_setting('vessel.id', true))
WITH CHECK (client_id = current_setting('vessel.client_id', false)); WITH CHECK (vessel_id = current_setting('vessel.id', false));
-- Allow scheduler to update and select based on the client_id -- Allow scheduler to update and select based on the vessel_id
CREATE POLICY api_scheduler_role ON api.stays TO scheduler CREATE POLICY api_scheduler_role ON api.stays TO scheduler
USING (client_id = current_setting('vessel.client_id', false)) USING (vessel_id = current_setting('vessel.id', false))
WITH CHECK (client_id = current_setting('vessel.client_id', false)); WITH CHECK (vessel_id = current_setting('vessel.id', false));
-- Allow grafana to select based on the client_id -- Allow grafana to select based on the vessel_id
CREATE POLICY grafana_role ON api.stays TO grafana CREATE POLICY grafana_role ON api.stays TO grafana
USING (client_id = current_setting('vessel.client_id', false)) USING (vessel_id = current_setting('vessel.id', false))
WITH CHECK (false); WITH CHECK (false);
-- Be sure to enable row level security on the table -- Be sure to enable row level security on the table
@@ -281,19 +281,19 @@ CREATE POLICY admin_all ON api.moorages TO current_user
WITH CHECK (true); WITH CHECK (true);
-- Allow vessel_role to insert and select on their own records -- Allow vessel_role to insert and select on their own records
CREATE POLICY api_vessel_role ON api.moorages TO vessel_role CREATE POLICY api_vessel_role ON api.moorages TO vessel_role
USING (client_id = current_setting('vessel.client_id', false)) USING (vessel_id = current_setting('vessel.id', false))
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 api.moorages TO user_role CREATE POLICY api_user_role ON api.moorages TO user_role
USING (client_id = current_setting('vessel.client_id', true)) USING (vessel_id = current_setting('vessel.id', true))
WITH CHECK (client_id = current_setting('vessel.client_id', false)); WITH CHECK (vessel_id = current_setting('vessel.id', false));
-- Allow scheduler to update and select based on the client_id -- Allow scheduler to update and select based on the vessel_id
CREATE POLICY api_scheduler_role ON api.moorages TO scheduler CREATE POLICY api_scheduler_role ON api.moorages TO scheduler
USING (client_id = current_setting('vessel.client_id', false)) USING (vessel_id = current_setting('vessel.id', false))
WITH CHECK (client_id = current_setting('vessel.client_id', false)); WITH CHECK (vessel_id = current_setting('vessel.id', false));
-- Allow grafana to select based on the client_id -- Allow grafana to select based on the vessel_id
CREATE POLICY grafana_role ON api.moorages TO grafana CREATE POLICY grafana_role ON api.moorages TO grafana
USING (client_id = current_setting('vessel.client_id', false)) USING (vessel_id = current_setting('vessel.id', false))
WITH CHECK (false); WITH CHECK (false);
-- Be sure to enable row level security on the table -- Be sure to enable row level security on the table