mirror of
https://github.com/xbgmsharp/postgsail.git
synced 2025-09-17 19:27:49 +00:00
Updates
This commit is contained in:
57
initdb/01signalk.sh
Executable file
57
initdb/01signalk.sh
Executable file
@@ -0,0 +1,57 @@
|
||||
#------------------------------------------------------------------------------
|
||||
# CUSTOMIZED OPTIONS
|
||||
#------------------------------------------------------------------------------
|
||||
|
||||
echo "CUSTOMIZED OPTIONS"
|
||||
echo $PGDATA
|
||||
echo "${PGDATA}/postgresql.conf"
|
||||
|
||||
cat << 'EOF' >> ${PGDATA}/postgresql.conf
|
||||
# PostgSail pg15
|
||||
# Add settings for extensions here
|
||||
shared_preload_libraries = 'timescaledb,pg_stat_statements,pg_cron'
|
||||
# TimescaleDB - time series database
|
||||
# Disable timescaleDB telemetry
|
||||
timescaledb.telemetry_level=off
|
||||
|
||||
# pg_cron - Run periodic jobs in PostgreSQL
|
||||
# pg_cron database
|
||||
#cron.database_name = 'signalk'
|
||||
# pg_cron connect via a unix domain socket
|
||||
cron.host = '/var/run/postgresql/'
|
||||
# Increase the number of available background workers from the default of 8
|
||||
#max_worker_processes = 8
|
||||
|
||||
# monitoring https://www.postgresql.org/docs/current/runtime-config-statistics.html#GUC-TRACK-IO-TIMING
|
||||
track_io_timing = on
|
||||
track_functions = all
|
||||
# Remove in pg-15, does not exist anymore
|
||||
#stats_temp_directory = '/tmp'
|
||||
|
||||
# PostgREST - turns your PostgreSQL database directly into a RESTful API
|
||||
# send logs where the collector can access them
|
||||
log_destination = 'stderr'
|
||||
# collect stderr output to log files
|
||||
#logging_collector = on
|
||||
# save logs in pg_log/ under the pg data directory
|
||||
#log_directory = 'pg_log'
|
||||
# (optional) new log file per day
|
||||
#log_filename = 'postgresql-%Y-%m-%d.log'
|
||||
# log every kind of SQL statement
|
||||
#log_statement = 'all'
|
||||
# Do not enable log_statement as its log format will not be parsed by pgBadger.
|
||||
|
||||
# pgBadger - a fast PostgreSQL log analysis report
|
||||
# log all the queries that are taking more than 1 second:
|
||||
#log_min_duration_statement = 1000
|
||||
#log_checkpoints = on
|
||||
#log_connections = on
|
||||
#log_disconnections = on
|
||||
#log_lock_waits = on
|
||||
#log_temp_files = 0
|
||||
#log_autovacuum_min_duration = 0
|
||||
#log_error_verbosity = default
|
||||
|
||||
# Francois
|
||||
log_min_messages = NOTICE
|
||||
EOF
|
83
initdb/01signalk.sql
Executable file
83
initdb/01signalk.sql
Executable file
@@ -0,0 +1,83 @@
|
||||
---------------------------------------------------------------------------
|
||||
-- PostgSail => Postgres + TimescaleDB + PostGIS + PostgREST
|
||||
--
|
||||
-- Inspired from:
|
||||
-- https://groups.google.com/g/signalk/c/W2H15ODCic4
|
||||
--
|
||||
-- Description:
|
||||
-- Insert data into table api.metadata from API using PostgREST
|
||||
-- Insert data into table api.metrics from API using PostgREST
|
||||
-- TimescaleDB Hypertable to store signalk metrics on table api.metrics
|
||||
-- pgsql functions to generate logbook, stays, moorages from table api.metrics
|
||||
-- CRON functions to process logbook, stays, moorages
|
||||
-- python functions for geo reverse and send notification via email, pushover, telegram
|
||||
-- Views statistics, timelapse, monitoring, logs
|
||||
-- Always store time in UTC
|
||||
---------------------------------------------------------------------------
|
||||
|
||||
-- vessels signalk -(POST)-> metadata -> metadata_upsert_trigger -(BEFORE INSERT)-> metadata_upsert_trigger_fn (INSERT or UPDATE)
|
||||
-- vessels signalk -(POST)-> metrics -> metrics_trigger -(BEFORE INSERT)-> metrics_trigger_fn (INSERT or UPDATE new log,stay)
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
|
||||
-- Drop database
|
||||
-- % docker exec -i timescaledb-postgis psql -Uusername -W postgres -c "drop database signalk;"
|
||||
|
||||
-- Import Schema
|
||||
-- % cat signalk.sql | docker exec -i timescaledb-postgis psql -Uusername postgres
|
||||
|
||||
-- Export hypertable
|
||||
-- % docker exec -i timescaledb-postgis psql -Uusername -W signalk -c "\COPY (SELECT * FROM api.metrics ORDER BY time ASC) TO '/var/lib/postgresql/data/metrics.csv' DELIMITER ',' CSV"
|
||||
-- Export hypertable to gzip
|
||||
-- # docker exec -i timescaledb-postgis psql -Uusername -W signalk -c "\COPY (SELECT * FROM api.metrics ORDER BY time ASC) TO PROGRAM 'gzip > /var/lib/postgresql/data/metrics.csv.gz' CSV HEADER;"
|
||||
|
||||
DO $$
|
||||
BEGIN
|
||||
RAISE WARNING '
|
||||
_________.__ .__ ____ __.
|
||||
/ _____/|__| ____ ____ _____ | | | |/ _|
|
||||
\_____ \ | |/ ___\ / \\__ \ | | | <
|
||||
/ \| / /_/ > | \/ __ \| |_| | \
|
||||
/_______ /|__\___ /|___| (____ /____/____|__ \
|
||||
\/ /_____/ \/ \/ \/
|
||||
%', now();
|
||||
END $$;
|
||||
|
||||
select version();
|
||||
|
||||
-- Database
|
||||
CREATE DATABASE signalk;
|
||||
-- Limit connection to 100
|
||||
ALTER DATABASE signalk WITH CONNECTION LIMIT = 100;
|
||||
-- Set timezone to UTC
|
||||
ALTER DATABASE signalk SET TIMEZONE='UTC';
|
||||
-- Set datestyle output
|
||||
ALTER DATABASE signalk SET datestyle TO "ISO, DMY";
|
||||
-- Set intervalstyle output
|
||||
ALTER DATABASE signalk SET intervalstyle TO 'iso_8601';
|
||||
|
||||
-- connect to the DB
|
||||
\c signalk
|
||||
|
||||
-- Schema
|
||||
CREATE SCHEMA IF NOT EXISTS api;
|
||||
COMMENT ON SCHEMA api IS
|
||||
$$PostgSail API
|
||||
|
||||
A RESTful API that serves PostgSail data using postgrest.$$;
|
||||
|
||||
-- Revoke default privileges to all public functions
|
||||
ALTER DEFAULT PRIVILEGES REVOKE EXECUTE ON FUNCTIONS FROM PUBLIC;
|
||||
|
||||
-- Extensions
|
||||
CREATE EXTENSION IF NOT EXISTS timescaledb; -- provides time series functions for PostgreSQL
|
||||
-- CREATE EXTENSION IF NOT EXISTS timescaledb_toolkit; -- provides time series functions for PostgreSQL
|
||||
CREATE EXTENSION IF NOT EXISTS postgis; -- adds support for geographic objects to the PostgreSQL object-relational database
|
||||
CREATE EXTENSION IF NOT EXISTS plpgsql; -- PL/pgSQL procedural language
|
||||
CREATE EXTENSION IF NOT EXISTS plpython3u; -- implements PL/Python based on the Python 3 language variant.
|
||||
CREATE EXTENSION IF NOT EXISTS jsonb_plpython3u CASCADE; -- tranform jsonb to python json type.
|
||||
CREATE EXTENSION IF NOT EXISTS pg_stat_statements; -- provides a means for tracking planning and execution statistics of all SQL statements executed
|
||||
CREATE EXTENSION IF NOT EXISTS "moddatetime"; -- provides functions for tracking last modification time
|
||||
|
||||
-- Trust plpython3u language by default
|
||||
UPDATE pg_language SET lanpltrusted = true WHERE lanname = 'plpython3u';
|
694
initdb/02_1_1_signalk_api_tables.sql
Normal file
694
initdb/02_1_1_signalk_api_tables.sql
Normal file
@@ -0,0 +1,694 @@
|
||||
|
||||
-- connect to the DB
|
||||
\c signalk
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Tables
|
||||
--
|
||||
---------------------------------------------------------------------------
|
||||
-- Metadata from signalk
|
||||
CREATE TABLE IF NOT EXISTS api.metadata(
|
||||
id INT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
name TEXT NULL,
|
||||
mmsi NUMERIC NULL,
|
||||
client_id TEXT NULL,
|
||||
-- vessel_id link auth.vessels with api.metadata
|
||||
vessel_id TEXT NOT NULL UNIQUE,
|
||||
length DOUBLE PRECISION NULL,
|
||||
beam DOUBLE PRECISION NULL,
|
||||
height DOUBLE PRECISION NULL,
|
||||
ship_type NUMERIC NULL,
|
||||
plugin_version TEXT NOT NULL,
|
||||
signalk_version TEXT NOT NULL,
|
||||
time TIMESTAMPTZ NOT NULL, -- should be rename to last_update !?
|
||||
platform TEXT NULL,
|
||||
configuration TEXT NULL,
|
||||
active BOOLEAN DEFAULT True, -- trigger monitor online/offline
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
-- Description
|
||||
COMMENT ON TABLE
|
||||
api.metadata
|
||||
IS 'Stores metadata received from vessel, aka signalk plugin';
|
||||
COMMENT ON COLUMN api.metadata.active IS 'trigger monitor online/offline';
|
||||
COMMENT ON COLUMN api.metadata.vessel_id IS 'vessel_id link auth.vessels with api.metadata';
|
||||
-- Duplicate Indexes
|
||||
--CREATE INDEX metadata_vessel_id_idx ON api.metadata (vessel_id);
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Metrics from signalk
|
||||
-- Create vessel status enum
|
||||
CREATE TYPE status_type AS ENUM ('sailing', 'motoring', 'moored', 'anchored');
|
||||
-- Table api.metrics
|
||||
CREATE TABLE IF NOT EXISTS api.metrics (
|
||||
time TIMESTAMPTZ NOT NULL,
|
||||
client_id TEXT NULL,
|
||||
vessel_id TEXT NOT NULL REFERENCES api.metadata(vessel_id) ON DELETE RESTRICT,
|
||||
latitude DOUBLE PRECISION NULL,
|
||||
longitude DOUBLE PRECISION NULL,
|
||||
speedOverGround DOUBLE PRECISION NULL,
|
||||
courseOverGroundTrue DOUBLE PRECISION NULL,
|
||||
windSpeedApparent DOUBLE PRECISION NULL,
|
||||
angleSpeedApparent DOUBLE PRECISION NULL,
|
||||
status TEXT NULL,
|
||||
metrics JSONB NULL,
|
||||
--CONSTRAINT valid_client_id CHECK (length(client_id) > 10),
|
||||
--CONSTRAINT valid_latitude CHECK (latitude >= -90 and latitude <= 90),
|
||||
--CONSTRAINT valid_longitude CHECK (longitude >= -180 and longitude <= 180),
|
||||
PRIMARY KEY (time, vessel_id)
|
||||
);
|
||||
-- Description
|
||||
COMMENT ON TABLE
|
||||
api.metrics
|
||||
IS 'Stores metrics from vessel';
|
||||
COMMENT ON COLUMN api.metrics.latitude 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
|
||||
CREATE INDEX ON api.metrics (vessel_id, time DESC);
|
||||
CREATE INDEX ON api.metrics (status, time DESC);
|
||||
-- json index??
|
||||
CREATE INDEX ON api.metrics using GIN (metrics);
|
||||
-- timescaledb hypertable
|
||||
SELECT create_hypertable('api.metrics', 'time', chunk_time_interval => INTERVAL '7 day');
|
||||
-- timescaledb hypertable with space partitions
|
||||
-- ERROR: new row for relation "_hyper_1_2_chunk" violates check constraint "constraint_4"
|
||||
-- ((_timescaledb_internal.get_partition_hash(vessel_id) < 1073741823))
|
||||
--SELECT create_hypertable('api.metrics', 'time', 'vessel_id',
|
||||
-- number_partitions => 2,
|
||||
-- chunk_time_interval => INTERVAL '7 day',
|
||||
-- if_not_exists => true);
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Logbook
|
||||
-- todo add consumption fuel?
|
||||
-- todo add engine hour?
|
||||
-- todo add geom object http://epsg.io/4326 EPSG:4326 Unit: degres
|
||||
-- todo add geog object http://epsg.io/3857 EPSG:3857 Unit: meters
|
||||
-- https://postgis.net/workshops/postgis-intro/geography.html#using-geography
|
||||
-- https://medium.com/coord/postgis-performance-showdown-geometry-vs-geography-ec99967da4f0
|
||||
-- virtual logbook by boat by client_id impossible?
|
||||
-- https://www.postgresql.org/docs/current/ddl-partitioning.html
|
||||
-- Issue:
|
||||
-- https://www.reddit.com/r/PostgreSQL/comments/di5mbr/postgresql_12_foreign_keys_and_partitioned_tables/f3tsoop/
|
||||
-- Check unused index
|
||||
|
||||
CREATE TABLE IF NOT EXISTS api.logbook(
|
||||
id INT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
vessel_id TEXT NOT NULL REFERENCES api.metadata(vessel_id) ON DELETE RESTRICT,
|
||||
active BOOLEAN DEFAULT false,
|
||||
name TEXT,
|
||||
_from_moorage_id INT NULL,
|
||||
_from TEXT,
|
||||
_from_lat DOUBLE PRECISION NULL,
|
||||
_from_lng DOUBLE PRECISION NULL,
|
||||
_to_moorage_id INT NULL,
|
||||
_to TEXT,
|
||||
_to_lat DOUBLE PRECISION NULL,
|
||||
_to_lng DOUBLE PRECISION NULL,
|
||||
--track_geom Geometry(LINESTRING)
|
||||
track_geom geometry(LINESTRING,4326) NULL,
|
||||
track_geog geography(LINESTRING) NULL,
|
||||
track_geojson JSONB NULL,
|
||||
_from_time TIMESTAMPTZ NOT NULL,
|
||||
_to_time TIMESTAMPTZ NULL,
|
||||
distance NUMERIC, -- meters?
|
||||
duration INTERVAL, -- duration in days and hours?
|
||||
avg_speed DOUBLE PRECISION NULL,
|
||||
max_speed DOUBLE PRECISION NULL,
|
||||
max_wind_speed DOUBLE PRECISION NULL,
|
||||
notes TEXT NULL, -- remarks
|
||||
extra JSONB NULL -- computed signalk metrics of interest
|
||||
);
|
||||
-- Description
|
||||
COMMENT ON TABLE
|
||||
api.logbook
|
||||
IS 'Stores generated logbook';
|
||||
COMMENT ON COLUMN api.logbook.distance IS 'in NM';
|
||||
COMMENT ON COLUMN api.logbook.extra IS 'computed signalk metrics of interest, runTime, currentLevel, etc';
|
||||
COMMENT ON COLUMN api.logbook.duration IS 'Best to use standard ISO 8601';
|
||||
|
||||
-- Index todo!
|
||||
CREATE INDEX logbook_vessel_id_idx ON api.logbook (vessel_id);
|
||||
CREATE INDEX logbook_from_time_idx ON api.logbook (_from_time);
|
||||
CREATE INDEX logbook_to_time_idx ON api.logbook (_to_time);
|
||||
CREATE INDEX logbook_from_moorage_id_idx ON api.logbook (_from_moorage_id);
|
||||
CREATE INDEX logbook_to_moorage_id_idx ON api.logbook (_to_moorage_id);
|
||||
CREATE INDEX ON api.logbook USING GIST ( track_geom );
|
||||
COMMENT ON COLUMN api.logbook.track_geom IS 'postgis geometry type EPSG:4326 Unit: degres';
|
||||
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';
|
||||
-- Otherwise -- ERROR: Only lon/lat coordinate systems are supported in geography.
|
||||
COMMENT ON COLUMN api.logbook.track_geojson IS 'store generated geojson with track metrics data using with LineString and Point features, we can not depend api.metrics table';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Stays
|
||||
-- virtual logbook by boat?
|
||||
CREATE TABLE IF NOT EXISTS api.stays(
|
||||
id INT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
vessel_id TEXT NOT NULL REFERENCES api.metadata(vessel_id) ON DELETE RESTRICT,
|
||||
active BOOLEAN DEFAULT false,
|
||||
moorage_id INT NULL,
|
||||
name TEXT,
|
||||
latitude DOUBLE PRECISION NULL,
|
||||
longitude DOUBLE PRECISION NULL,
|
||||
geog GEOGRAPHY(POINT) NULL,
|
||||
arrived TIMESTAMPTZ NOT NULL,
|
||||
departed TIMESTAMPTZ,
|
||||
duration INTERVAL, -- duration in days and hours?
|
||||
stay_code INT DEFAULT 1, -- REFERENCES api.stays_at(stay_code),
|
||||
notes TEXT NULL
|
||||
);
|
||||
-- Description
|
||||
COMMENT ON TABLE
|
||||
api.stays
|
||||
IS 'Stores generated stays';
|
||||
COMMENT ON COLUMN api.stays.duration IS 'Best to use standard ISO 8601';
|
||||
|
||||
-- Index
|
||||
CREATE INDEX stays_vessel_id_idx ON api.stays (vessel_id);
|
||||
CREATE INDEX stays_moorage_id_idx ON api.stays (moorage_id);
|
||||
CREATE INDEX ON api.stays USING GIST ( geog );
|
||||
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.
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Moorages
|
||||
-- virtual logbook by boat?
|
||||
CREATE TABLE IF NOT EXISTS api.moorages(
|
||||
id INT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
vessel_id TEXT NOT NULL REFERENCES api.metadata(vessel_id) ON DELETE RESTRICT,
|
||||
name TEXT,
|
||||
country TEXT,
|
||||
stay_code INT DEFAULT 1, -- needed? REFERENCES api.stays_at(stay_code)
|
||||
stay_duration INTERVAL NULL,
|
||||
reference_count INT DEFAULT 1,
|
||||
latitude DOUBLE PRECISION NULL,
|
||||
longitude DOUBLE PRECISION NULL,
|
||||
geog GEOGRAPHY(POINT) NULL,
|
||||
home_flag BOOLEAN DEFAULT false,
|
||||
notes TEXT NULL,
|
||||
overpass JSONB NULL,
|
||||
nominatim JSONB NULL
|
||||
);
|
||||
-- Description
|
||||
COMMENT ON TABLE
|
||||
api.moorages
|
||||
IS 'Stores generated moorages';
|
||||
|
||||
-- Index
|
||||
CREATE INDEX moorages_vessel_id_idx ON api.moorages (vessel_id);
|
||||
CREATE INDEX ON api.moorages USING GIST ( geog );
|
||||
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.
|
||||
COMMENT ON COLUMN api.moorages.stay_duration IS 'Best to use standard ISO 8601';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Stay Type
|
||||
CREATE TABLE IF NOT EXISTS api.stays_at(
|
||||
stay_code INTEGER UNIQUE NOT NULL,
|
||||
description TEXT NOT NULL
|
||||
);
|
||||
-- Description
|
||||
COMMENT ON TABLE api.stays_at IS 'Stay Type';
|
||||
-- Insert default possible values
|
||||
INSERT INTO api.stays_at(stay_code, description) VALUES
|
||||
(1, 'Unknown'),
|
||||
(2, 'Anchor'),
|
||||
(3, 'Mooring Buoy'),
|
||||
(4, 'Dock');
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Trigger Functions Metadata table
|
||||
--
|
||||
-- UPSERT - Insert vs Update for Metadata
|
||||
DROP FUNCTION IF EXISTS metadata_upsert_trigger_fn;
|
||||
CREATE FUNCTION metadata_upsert_trigger_fn() RETURNS trigger AS $metadata_upsert$
|
||||
DECLARE
|
||||
metadata_id integer;
|
||||
metadata_active boolean;
|
||||
BEGIN
|
||||
-- Set client_id to new value to allow RLS
|
||||
--PERFORM set_config('vessel.client_id', NEW.client_id, false);
|
||||
-- UPSERT - Insert vs Update for Metadata
|
||||
--RAISE NOTICE 'metadata_upsert_trigger_fn';
|
||||
--PERFORM set_config('vessel.id', NEW.vessel_id, true);
|
||||
--RAISE WARNING 'metadata_upsert_trigger_fn [%] [%]', current_setting('vessel.id', true), NEW;
|
||||
SELECT m.id,m.active INTO metadata_id, metadata_active
|
||||
FROM api.metadata m
|
||||
WHERE m.vessel_id IS NOT NULL AND m.vessel_id = current_setting('vessel.id', true);
|
||||
--RAISE NOTICE 'metadata_id is [%]', metadata_id;
|
||||
IF metadata_id IS NOT NULL THEN
|
||||
-- send notification if boat is back online
|
||||
IF metadata_active is False THEN
|
||||
-- Add monitor online entry to process queue for later notification
|
||||
INSERT INTO process_queue (channel, payload, stored, ref_id)
|
||||
VALUES ('monitoring_online', metadata_id, now(), current_setting('vessel.id', true));
|
||||
END IF;
|
||||
-- Update vessel metadata
|
||||
UPDATE api.metadata
|
||||
SET
|
||||
name = NEW.name,
|
||||
mmsi = NEW.mmsi,
|
||||
client_id = NEW.client_id,
|
||||
length = NEW.length,
|
||||
beam = NEW.beam,
|
||||
height = NEW.height,
|
||||
ship_type = NEW.ship_type,
|
||||
plugin_version = NEW.plugin_version,
|
||||
signalk_version = NEW.signalk_version,
|
||||
platform = NEW.platform,
|
||||
configuration = NEW.configuration,
|
||||
-- time = NEW.time, ignore the time sent by the vessel as it is out of sync sometimes.
|
||||
time = NOW(), -- overwrite the time sent by the vessel
|
||||
active = true
|
||||
WHERE id = metadata_id;
|
||||
RETURN NULL; -- Ignore insert
|
||||
ELSE
|
||||
IF NEW.vessel_id IS NULL THEN
|
||||
-- set vessel_id from jwt if not present in INSERT query
|
||||
NEW.vessel_id := current_setting('vessel.id');
|
||||
END IF;
|
||||
-- Ignore and overwrite the time sent by the vessel
|
||||
NEW.time := NOW();
|
||||
-- Insert new vessel metadata
|
||||
RETURN NEW; -- Insert new vessel metadata
|
||||
END IF;
|
||||
END;
|
||||
$metadata_upsert$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.metadata_upsert_trigger_fn
|
||||
IS 'process metadata from vessel, upsert';
|
||||
|
||||
CREATE TRIGGER metadata_moddatetime
|
||||
BEFORE UPDATE ON api.metadata
|
||||
FOR EACH ROW
|
||||
EXECUTE PROCEDURE moddatetime (updated_at);
|
||||
-- Description
|
||||
COMMENT ON TRIGGER metadata_moddatetime
|
||||
ON api.metadata
|
||||
IS 'Automatic update of updated_at on table modification';
|
||||
|
||||
-- FUNCTION Metadata notification for new vessel after insert
|
||||
DROP FUNCTION IF EXISTS metadata_notification_trigger_fn;
|
||||
CREATE FUNCTION metadata_notification_trigger_fn() RETURNS trigger AS $metadata_notification$
|
||||
DECLARE
|
||||
BEGIN
|
||||
RAISE NOTICE 'metadata_notification_trigger_fn [%]', NEW;
|
||||
INSERT INTO process_queue (channel, payload, stored, ref_id)
|
||||
VALUES ('monitoring_online', NEW.id, now(), NEW.vessel_id);
|
||||
RETURN NULL;
|
||||
END;
|
||||
$metadata_notification$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.metadata_notification_trigger_fn
|
||||
IS 'process metadata notification from vessel, monitoring_online';
|
||||
|
||||
-- FUNCTION Metadata grafana provisioning for new vessel after insert
|
||||
DROP FUNCTION IF EXISTS metadata_grafana_trigger_fn;
|
||||
CREATE FUNCTION metadata_grafana_trigger_fn() RETURNS trigger AS $metadata_grafana$
|
||||
DECLARE
|
||||
BEGIN
|
||||
RAISE NOTICE 'metadata_grafana_trigger_fn [%]', NEW;
|
||||
INSERT INTO process_queue (channel, payload, stored, ref_id)
|
||||
VALUES ('grafana', NEW.id, now(), NEW.vessel_id);
|
||||
RETURN NULL;
|
||||
END;
|
||||
$metadata_grafana$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.metadata_grafana_trigger_fn
|
||||
IS 'process metadata grafana provisioning from vessel';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Trigger metadata table
|
||||
--
|
||||
-- Metadata trigger BEFORE INSERT
|
||||
CREATE TRIGGER metadata_upsert_trigger BEFORE INSERT ON api.metadata
|
||||
FOR EACH ROW EXECUTE FUNCTION metadata_upsert_trigger_fn();
|
||||
-- Description
|
||||
COMMENT ON TRIGGER
|
||||
metadata_upsert_trigger ON api.metadata
|
||||
IS 'BEFORE INSERT ON api.metadata run function metadata_upsert_trigger_fn';
|
||||
|
||||
-- Metadata trigger AFTER INSERT
|
||||
CREATE TRIGGER metadata_notification_trigger AFTER INSERT ON api.metadata
|
||||
FOR EACH ROW EXECUTE FUNCTION metadata_notification_trigger_fn();
|
||||
-- Description
|
||||
COMMENT ON TRIGGER
|
||||
metadata_notification_trigger ON api.metadata
|
||||
IS 'AFTER INSERT ON api.metadata run function metadata_notification_trigger_fn for later notification on new vessel';
|
||||
|
||||
-- Metadata trigger AFTER INSERT
|
||||
CREATE TRIGGER metadata_grafana_trigger AFTER INSERT ON api.metadata
|
||||
FOR EACH ROW EXECUTE FUNCTION metadata_grafana_trigger_fn();
|
||||
-- Description
|
||||
COMMENT ON TRIGGER
|
||||
metadata_grafana_trigger ON api.metadata
|
||||
IS 'AFTER INSERT ON api.metadata run function metadata_grafana_trigger_fn for later grafana provisioning on new vessel';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Trigger Functions metrics table
|
||||
--
|
||||
-- Create a logbook or stay entry base on the vessel state, eg: navigation.state
|
||||
-- https://github.com/meri-imperiumi/signalk-autostate
|
||||
|
||||
DROP FUNCTION IF EXISTS metrics_trigger_fn;
|
||||
CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
|
||||
DECLARE
|
||||
previous_metric record;
|
||||
stay_code INTEGER;
|
||||
logbook_id INTEGER;
|
||||
stay_id INTEGER;
|
||||
valid_status BOOLEAN := False;
|
||||
_vessel_id TEXT;
|
||||
distance BOOLEAN := False;
|
||||
BEGIN
|
||||
--RAISE NOTICE 'metrics_trigger_fn';
|
||||
--RAISE WARNING 'metrics_trigger_fn [%] [%]', current_setting('vessel.id', true), NEW;
|
||||
-- Ensure vessel.id to new value to allow RLS
|
||||
IF NEW.vessel_id IS NULL THEN
|
||||
-- set vessel_id from jwt if not present in INSERT query
|
||||
NEW.vessel_id := current_setting('vessel.id');
|
||||
END IF;
|
||||
-- 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
|
||||
SELECT * INTO previous_metric
|
||||
FROM api.metrics m
|
||||
WHERE m.vessel_id IS NOT NULL
|
||||
AND m.vessel_id = current_setting('vessel.id', true)
|
||||
ORDER BY m.time DESC LIMIT 1;
|
||||
--RAISE NOTICE 'Metrics Status, New:[%] Previous:[%]', NEW.status, previous_metric.status;
|
||||
IF previous_metric.time = NEW.time THEN
|
||||
-- Ignore entry if same time
|
||||
RAISE WARNING 'Metrics Ignoring metric, vessel_id [%], duplicate time [%] = [%]', NEW.vessel_id, previous_metric.time, NEW.time;
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
IF previous_metric.time > NEW.time THEN
|
||||
-- Ignore entry if new time is later than previous time
|
||||
RAISE WARNING 'Metrics Ignoring metric, vessel_id [%], new time is older than previous_metric.time [%] > [%]', NEW.vessel_id, previous_metric.time, NEW.time;
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
-- Check if latitude or longitude are type double
|
||||
--IF public.isdouble(NEW.latitude::TEXT) IS False OR public.isdouble(NEW.longitude::TEXT) IS False THEN
|
||||
-- -- Ignore entry if null latitude,longitude
|
||||
-- RAISE WARNING 'Metrics Ignoring metric, vessel_id [%], not a double type for latitude or longitude [%] [%]', NEW.vessel_id, NEW.latitude, NEW.longitude;
|
||||
-- RETURN NULL;
|
||||
--END IF;
|
||||
-- Check if latitude or longitude are null
|
||||
IF NEW.latitude IS NULL OR NEW.longitude IS NULL THEN
|
||||
-- Ignore entry if null latitude,longitude
|
||||
RAISE WARNING 'Metrics Ignoring metric, vessel_id [%], null latitude or longitude [%] [%]', NEW.vessel_id, NEW.latitude, NEW.longitude;
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
-- Check if valid latitude
|
||||
IF NEW.latitude >= 90 OR NEW.latitude <= -90 THEN
|
||||
-- Ignore entry if invalid latitude,longitude
|
||||
RAISE WARNING 'Metrics Ignoring metric, vessel_id [%], invalid latitude >= 90 OR <= -90 [%] [%]', NEW.vessel_id, NEW.latitude, NEW.longitude;
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
-- Check if valid longitude
|
||||
IF NEW.longitude >= 180 OR NEW.longitude <= -180 THEN
|
||||
-- Ignore entry if invalid latitude,longitude
|
||||
RAISE WARNING 'Metrics Ignoring metric, vessel_id [%], invalid longitude >= 180 OR <= -180 [%] [%]', NEW.vessel_id, NEW.latitude, NEW.longitude;
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
-- Check if valid longitude and latitude not close to -0.0000001 from Victron Cerbo
|
||||
IF NEW.latitude = NEW.longitude THEN
|
||||
-- Ignore entry if latitude,longitude are equal
|
||||
RAISE WARNING 'Metrics Ignoring metric, vessel_id [%], latitude and longitude are equal [%] [%]', NEW.vessel_id, NEW.latitude, NEW.longitude;
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
-- Check distance with previous point is > 10km
|
||||
--SELECT ST_Distance(
|
||||
-- ST_MakePoint(NEW.latitude,NEW.longitude)::geography,
|
||||
-- ST_MakePoint(previous_metric.latitude,previous_metric.longitude)::geography) > 10000 INTO distance;
|
||||
--IF distance IS True THEN
|
||||
-- RAISE WARNING 'Metrics Ignoring metric, distance between previous metric and new metric is too large, vessel_id [%] distance[%]', NEW.vessel_id, distance;
|
||||
-- RETURN NULL;
|
||||
--END IF;
|
||||
-- Check if status is null but speed is over 3knots set status to sailing
|
||||
IF NEW.status IS NULL AND NEW.speedoverground >= 3 THEN
|
||||
RAISE WARNING 'Metrics Unknown NEW.status, vessel_id [%], null status, set to sailing because of speedoverground is +3 from [%]', NEW.vessel_id, NEW.status;
|
||||
NEW.status := 'sailing';
|
||||
-- Check if status is null then set status to default moored
|
||||
ELSIF NEW.status IS NULL THEN
|
||||
RAISE WARNING 'Metrics Unknown NEW.status, vessel_id [%], null status, set to default moored from [%]', NEW.vessel_id, NEW.status;
|
||||
NEW.status := 'moored';
|
||||
END IF;
|
||||
IF previous_metric.status IS NULL THEN
|
||||
IF NEW.status = 'anchored' THEN
|
||||
RAISE WARNING 'Metrics Unknown previous_metric.status from vessel_id [%], [%] set to default current status [%]', NEW.vessel_id, previous_metric.status, NEW.status;
|
||||
previous_metric.status := NEW.status;
|
||||
ELSE
|
||||
RAISE WARNING 'Metrics Unknown previous_metric.status from vessel_id [%], [%] set to default status moored vs [%]', NEW.vessel_id, previous_metric.status, NEW.status;
|
||||
previous_metric.status := 'moored';
|
||||
END IF;
|
||||
-- Add new stay as no previous entry exist
|
||||
INSERT INTO api.stays
|
||||
(vessel_id, active, arrived, latitude, longitude, stay_code)
|
||||
VALUES (current_setting('vessel.id', true), true, NEW.time, NEW.latitude, NEW.longitude, 1)
|
||||
RETURNING id INTO stay_id;
|
||||
-- Add stay entry to process queue for further processing
|
||||
INSERT INTO process_queue (channel, payload, stored, ref_id)
|
||||
VALUES ('new_stay', stay_id, now(), current_setting('vessel.id', true));
|
||||
RAISE WARNING 'Metrics Insert first stay as no previous metrics exist, stay_id stay_id [%] [%] [%]', stay_id, NEW.status, NEW.time;
|
||||
END IF;
|
||||
-- Check if status is valid enum
|
||||
SELECT NEW.status::name = any(enum_range(null::status_type)::name[]) INTO valid_status;
|
||||
IF valid_status IS False THEN
|
||||
-- Ignore entry if status is invalid
|
||||
RAISE WARNING 'Metrics Ignoring metric, vessel_id [%], invalid status [%]', NEW.vessel_id, NEW.status;
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
-- Check if speedOverGround is valid value
|
||||
IF NEW.speedoverground >= 40 THEN
|
||||
-- Ignore entry as speedOverGround is invalid
|
||||
RAISE WARNING 'Metrics Ignoring metric, vessel_id [%], speedOverGround is invalid, over 40 < [%]', NEW.vessel_id, NEW.speedoverground;
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
|
||||
-- Check the state and if any previous/current entry
|
||||
-- If change of state and new status is sailing or motoring
|
||||
IF previous_metric.status::TEXT <> NEW.status::TEXT AND
|
||||
( (NEW.status::TEXT = 'sailing' AND previous_metric.status::TEXT <> 'motoring')
|
||||
OR (NEW.status::TEXT = 'motoring' AND previous_metric.status::TEXT <> 'sailing') ) THEN
|
||||
RAISE WARNING 'Metrics Update status, try new logbook, New:[%] Previous:[%]', NEW.status, previous_metric.status;
|
||||
-- Start new log
|
||||
logbook_id := public.trip_in_progress_fn(current_setting('vessel.id', true)::TEXT);
|
||||
IF logbook_id IS NULL THEN
|
||||
INSERT INTO api.logbook
|
||||
(vessel_id, active, _from_time, _from_lat, _from_lng)
|
||||
VALUES (current_setting('vessel.id', true), true, NEW.time, NEW.latitude, NEW.longitude)
|
||||
RETURNING id INTO logbook_id;
|
||||
RAISE WARNING 'Metrics Insert new logbook, logbook_id [%] [%] [%]', logbook_id, NEW.status, NEW.time;
|
||||
ELSE
|
||||
UPDATE api.logbook
|
||||
SET
|
||||
active = false,
|
||||
_to_time = NEW.time,
|
||||
_to_lat = NEW.latitude,
|
||||
_to_lng = NEW.longitude
|
||||
WHERE id = logbook_id;
|
||||
RAISE WARNING 'Metrics Existing logbook logbook_id [%] [%] [%]', logbook_id, NEW.status, NEW.time;
|
||||
END IF;
|
||||
|
||||
-- End current stay
|
||||
stay_id := public.stay_in_progress_fn(current_setting('vessel.id', true)::TEXT);
|
||||
IF stay_id IS NOT NULL THEN
|
||||
UPDATE api.stays
|
||||
SET
|
||||
active = false,
|
||||
departed = NEW.time
|
||||
WHERE id = stay_id;
|
||||
-- Add stay entry to process queue for further processing
|
||||
INSERT INTO process_queue (channel, payload, stored, ref_id)
|
||||
VALUES ('new_stay', stay_id, NOW(), current_setting('vessel.id', true));
|
||||
RAISE WARNING 'Metrics Updating Stay end current stay_id [%] [%] [%]', stay_id, NEW.status, NEW.time;
|
||||
ELSE
|
||||
RAISE WARNING 'Metrics Invalid stay_id [%] [%]', stay_id, NEW.time;
|
||||
END IF;
|
||||
|
||||
-- If change of state and new status is moored or anchored
|
||||
ELSIF previous_metric.status::TEXT <> NEW.status::TEXT AND
|
||||
( (NEW.status::TEXT = 'moored' AND previous_metric.status::TEXT <> 'anchored')
|
||||
OR (NEW.status::TEXT = 'anchored' AND previous_metric.status::TEXT <> 'moored') ) THEN
|
||||
-- Start new stays
|
||||
RAISE WARNING 'Metrics Update status, try new stay, New:[%] Previous:[%]', NEW.status, previous_metric.status;
|
||||
stay_id := public.stay_in_progress_fn(current_setting('vessel.id', true)::TEXT);
|
||||
IF stay_id IS NULL THEN
|
||||
RAISE WARNING 'Metrics Inserting new stay [%]', NEW.status;
|
||||
-- If metric status is anchored set stay_code accordingly
|
||||
stay_code = 1;
|
||||
IF NEW.status = 'anchored' THEN
|
||||
stay_code = 2;
|
||||
END IF;
|
||||
-- Add new stay
|
||||
INSERT INTO api.stays
|
||||
(vessel_id, active, arrived, latitude, longitude, stay_code)
|
||||
VALUES (current_setting('vessel.id', true), true, NEW.time, NEW.latitude, NEW.longitude, stay_code)
|
||||
RETURNING id INTO stay_id;
|
||||
RAISE WARNING 'Metrics Insert new stay, stay_id [%] [%] [%]', stay_id, NEW.status, NEW.time;
|
||||
ELSE
|
||||
RAISE WARNING 'Metrics Invalid stay_id [%] [%]', stay_id, NEW.time;
|
||||
UPDATE api.stays
|
||||
SET
|
||||
active = false,
|
||||
departed = NEW.time,
|
||||
notes = 'Invalid stay?'
|
||||
WHERE id = stay_id;
|
||||
END IF;
|
||||
|
||||
-- End current log/trip
|
||||
-- Fetch logbook_id by vessel_id
|
||||
logbook_id := public.trip_in_progress_fn(current_setting('vessel.id', true)::TEXT);
|
||||
IF logbook_id IS NOT NULL THEN
|
||||
-- todo check on time start vs end
|
||||
RAISE WARNING 'Metrics Updating logbook status [%] [%] [%]', logbook_id, NEW.status, NEW.time;
|
||||
UPDATE api.logbook
|
||||
SET
|
||||
active = false,
|
||||
_to_time = NEW.time,
|
||||
_to_lat = NEW.latitude,
|
||||
_to_lng = NEW.longitude
|
||||
WHERE id = logbook_id;
|
||||
-- Add logbook entry to process queue for later processing
|
||||
INSERT INTO process_queue (channel, payload, stored, ref_id)
|
||||
VALUES ('pre_logbook', logbook_id, NOW(), current_setting('vessel.id', true));
|
||||
ELSE
|
||||
RAISE WARNING 'Metrics Invalid logbook_id [%] [%] [%]', logbook_id, NEW.status, NEW.time;
|
||||
END IF;
|
||||
END IF;
|
||||
RETURN NEW; -- Finally insert the actual new metric
|
||||
END;
|
||||
$metrics$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.metrics_trigger_fn
|
||||
IS 'process metrics from vessel, generate pre_logbook and new_stay.';
|
||||
|
||||
--
|
||||
-- Triggers logbook update on metrics insert
|
||||
CREATE TRIGGER metrics_trigger BEFORE INSERT ON api.metrics
|
||||
FOR EACH ROW EXECUTE FUNCTION metrics_trigger_fn();
|
||||
-- Description
|
||||
COMMENT ON TRIGGER
|
||||
metrics_trigger ON api.metrics
|
||||
IS 'BEFORE INSERT ON api.metrics run function metrics_trigger_fn';
|
||||
|
||||
-- Function update of name and stay_code on logbook and stays reference
|
||||
DROP FUNCTION IF EXISTS moorage_update_trigger_fn;
|
||||
CREATE FUNCTION moorage_update_trigger_fn() RETURNS trigger AS $moorage_update$
|
||||
DECLARE
|
||||
BEGIN
|
||||
RAISE NOTICE 'moorages_update_trigger_fn [%]', NEW;
|
||||
IF ( OLD.name != NEW.name) THEN
|
||||
UPDATE api.logbook SET _from = NEW.name WHERE _from_moorage_id = NEW.id;
|
||||
UPDATE api.logbook SET _to = NEW.name WHERE _to_moorage_id = NEW.id;
|
||||
END IF;
|
||||
IF ( OLD.stay_code != NEW.stay_code) THEN
|
||||
UPDATE api.stays SET stay_code = NEW.stay_code WHERE moorage_id = NEW.id;
|
||||
END IF;
|
||||
RETURN NULL; -- result is ignored since this is an AFTER trigger
|
||||
END;
|
||||
$moorage_update$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.moorage_update_trigger_fn
|
||||
IS 'Automatic update of name and stay_code on logbook and stays reference';
|
||||
|
||||
-- Triggers moorage update after update
|
||||
CREATE TRIGGER moorage_update_trigger AFTER UPDATE ON api.moorages
|
||||
FOR EACH ROW EXECUTE FUNCTION moorage_update_trigger_fn();
|
||||
-- Description
|
||||
COMMENT ON TRIGGER moorage_update_trigger
|
||||
ON api.moorages
|
||||
IS 'Automatic update of name and stay_code on logbook and stays reference';
|
||||
|
||||
-- Function delete logbook and stays reference when delete a moorage
|
||||
DROP FUNCTION IF EXISTS moorage_delete_trigger_fn;
|
||||
CREATE FUNCTION moorage_delete_trigger_fn() RETURNS trigger AS $moorage_delete$
|
||||
DECLARE
|
||||
BEGIN
|
||||
RAISE NOTICE 'moorages_delete_trigger_fn [%]', OLD;
|
||||
DELETE FROM api.stays WHERE moorage_id = OLD.id;
|
||||
DELETE FROM api.logbook WHERE _from_moorage_id = OLD.id;
|
||||
DELETE FROM api.logbook WHERE _to_moorage_id = OLD.id;
|
||||
RETURN OLD; -- result is ignored since this is an AFTER trigger
|
||||
END;
|
||||
$moorage_delete$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.moorage_delete_trigger_fn
|
||||
IS 'Automatic delete logbook and stays reference when delete a moorage';
|
||||
|
||||
-- Triggers moorage delete
|
||||
CREATE TRIGGER moorage_delete_trigger BEFORE DELETE ON api.moorages
|
||||
FOR EACH ROW EXECUTE FUNCTION moorage_delete_trigger_fn();
|
||||
-- Description
|
||||
COMMENT ON TRIGGER moorage_delete_trigger
|
||||
ON api.moorages
|
||||
IS 'Automatic delete logbook and stays reference when delete a moorage';
|
||||
|
||||
-- Function process_new on completed logbook
|
||||
DROP FUNCTION IF EXISTS logbook_completed_trigger_fn;
|
||||
CREATE FUNCTION logbook_completed_trigger_fn() RETURNS trigger AS $logbook_completed$
|
||||
DECLARE
|
||||
BEGIN
|
||||
RAISE NOTICE 'logbook_completed_trigger_fn [%]', OLD;
|
||||
RAISE NOTICE 'logbook_completed_trigger_fn [%] [%]', OLD._to_time, NEW._to_time;
|
||||
-- Add logbook entry to process queue for later processing
|
||||
--IF ( OLD._to_time <> NEW._to_time ) THEN
|
||||
INSERT INTO process_queue (channel, payload, stored, ref_id)
|
||||
VALUES ('new_logbook', NEW.id, NOW(), current_setting('vessel.id', true));
|
||||
--END IF;
|
||||
RETURN OLD; -- result is ignored since this is an AFTER trigger
|
||||
END;
|
||||
$logbook_completed$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.logbook_completed_trigger_fn
|
||||
IS 'Automatic process_queue for completed logbook._to_time';
|
||||
|
||||
-- Triggers logbook completed
|
||||
--CREATE TRIGGER logbook_completed_trigger AFTER UPDATE ON api.logbook
|
||||
-- FOR EACH ROW
|
||||
-- WHEN (OLD._to_time IS DISTINCT FROM NEW._to_time)
|
||||
-- EXECUTE FUNCTION logbook_completed_trigger_fn();
|
||||
-- Description
|
||||
--COMMENT ON TRIGGER logbook_completed_trigger
|
||||
-- ON api.logbook
|
||||
-- IS 'Automatic process_queue for completed logbook';
|
||||
|
||||
-- Function process_new on completed Stay
|
||||
DROP FUNCTION IF EXISTS stay_completed_trigger_fn;
|
||||
CREATE FUNCTION stay_completed_trigger_fn() RETURNS trigger AS $stay_completed$
|
||||
DECLARE
|
||||
BEGIN
|
||||
RAISE NOTICE 'stay_completed_trigger_fn [%]', OLD;
|
||||
RAISE NOTICE 'stay_completed_trigger_fn [%] [%]', OLD.departed, NEW.departed;
|
||||
-- Add stay entry to process queue for later processing
|
||||
--IF ( OLD.departed <> NEW.departed ) THEN
|
||||
INSERT INTO process_queue (channel, payload, stored, ref_id)
|
||||
VALUES ('new_stay', NEW.id, NOW(), current_setting('vessel.id', true));
|
||||
--END IF;
|
||||
RETURN OLD; -- result is ignored since this is an AFTER trigger
|
||||
END;
|
||||
$stay_completed$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.stay_completed_trigger_fn
|
||||
IS 'Automatic process_queue for completed stay.departed';
|
||||
|
||||
-- Triggers stay completed
|
||||
--CREATE TRIGGER stay_completed_trigger AFTER UPDATE ON api.stays
|
||||
-- FOR EACH ROW
|
||||
-- WHEN (OLD.departed IS DISTINCT FROM NEW.departed)
|
||||
-- EXECUTE FUNCTION stay_completed_trigger_fn();
|
||||
-- Description
|
||||
--COMMENT ON TRIGGER stay_completed_trigger
|
||||
-- ON api.stays
|
||||
-- IS 'Automatic process_queue for completed stay';
|
938
initdb/02_1_2_signalk_api_functions.sql
Normal file
938
initdb/02_1_2_signalk_api_functions.sql
Normal file
@@ -0,0 +1,938 @@
|
||||
|
||||
-- connect to the DB
|
||||
\c signalk
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- API helper functions
|
||||
--
|
||||
---------------------------------------------------------------------------
|
||||
|
||||
-- PostgREST Media Type Handlers
|
||||
CREATE DOMAIN "text/xml" AS xml;
|
||||
CREATE DOMAIN "application/geo+json" AS jsonb;
|
||||
CREATE DOMAIN "application/gpx+xml" AS xml;
|
||||
CREATE DOMAIN "application/vnd.google-earth.kml+xml" AS xml;
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Functions API schema
|
||||
-- Timelapse - replay logs
|
||||
DROP FUNCTION IF EXISTS api.timelapse_fn;
|
||||
CREATE OR REPLACE FUNCTION api.timelapse_fn(
|
||||
IN start_log INTEGER DEFAULT NULL,
|
||||
IN end_log INTEGER DEFAULT NULL,
|
||||
IN start_date TEXT DEFAULT NULL,
|
||||
IN end_date TEXT DEFAULT NULL,
|
||||
OUT geojson JSONB) RETURNS JSONB AS $timelapse$
|
||||
DECLARE
|
||||
_geojson jsonb;
|
||||
BEGIN
|
||||
-- Using sub query to force id order by
|
||||
-- Merge GIS track_geom into a GeoJSON MultiLineString
|
||||
IF start_log IS NOT NULL AND public.isnumeric(start_log::text) AND public.isnumeric(end_log::text) THEN
|
||||
WITH logbook as (
|
||||
SELECT track_geom
|
||||
FROM api.logbook
|
||||
WHERE id >= start_log
|
||||
AND id <= end_log
|
||||
AND track_geom IS NOT NULL
|
||||
ORDER BY _from_time ASC
|
||||
)
|
||||
SELECT ST_AsGeoJSON(geo.*) INTO _geojson FROM (
|
||||
SELECT ST_Collect(
|
||||
ARRAY(
|
||||
SELECT track_geom FROM logbook))
|
||||
) as geo;
|
||||
--raise WARNING 'by log id _geojson %' , _geojson;
|
||||
ELSIF start_date IS NOT NULL AND public.isdate(start_date::text) AND public.isdate(end_date::text) THEN
|
||||
WITH logbook as (
|
||||
SELECT track_geom
|
||||
FROM api.logbook
|
||||
WHERE _from_time >= start_date::TIMESTAMPTZ
|
||||
AND _to_time <= end_date::TIMESTAMPTZ + interval '23 hours 59 minutes'
|
||||
AND track_geom IS NOT NULL
|
||||
ORDER BY _from_time ASC
|
||||
)
|
||||
SELECT ST_AsGeoJSON(geo.*) INTO _geojson FROM (
|
||||
SELECT ST_Collect(
|
||||
ARRAY(
|
||||
SELECT track_geom FROM logbook))
|
||||
) as geo;
|
||||
--raise WARNING 'by date _geojson %' , _geojson;
|
||||
ELSE
|
||||
WITH logbook as (
|
||||
SELECT track_geom
|
||||
FROM api.logbook
|
||||
WHERE track_geom IS NOT NULL
|
||||
ORDER BY _from_time ASC
|
||||
)
|
||||
SELECT ST_AsGeoJSON(geo.*) INTO _geojson FROM (
|
||||
SELECT ST_Collect(
|
||||
ARRAY(
|
||||
SELECT track_geom FROM logbook))
|
||||
) as geo;
|
||||
--raise WARNING 'all result _geojson %' , _geojson;
|
||||
END IF;
|
||||
-- Return a GeoJSON MultiLineString
|
||||
-- result _geojson [null, null]
|
||||
--raise WARNING 'result _geojson %' , _geojson;
|
||||
SELECT jsonb_build_object(
|
||||
'type', 'FeatureCollection',
|
||||
'features', ARRAY[_geojson] ) INTO geojson;
|
||||
END;
|
||||
$timelapse$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.timelapse_fn
|
||||
IS 'Export all selected logs geometry `track_geom` to a geojson as MultiLineString with empty properties';
|
||||
|
||||
DROP FUNCTION IF EXISTS api.timelapse2_fn;
|
||||
CREATE OR REPLACE FUNCTION api.timelapse2_fn(
|
||||
IN start_log INTEGER DEFAULT NULL,
|
||||
IN end_log INTEGER DEFAULT NULL,
|
||||
IN start_date TEXT DEFAULT NULL,
|
||||
IN end_date TEXT DEFAULT NULL,
|
||||
OUT geojson JSONB) RETURNS JSONB AS $timelapse2$
|
||||
DECLARE
|
||||
_geojson jsonb;
|
||||
BEGIN
|
||||
-- Using sub query to force id order by
|
||||
-- Merge GIS track_geom into a GeoJSON Points
|
||||
IF start_log IS NOT NULL AND public.isnumeric(start_log::text) AND public.isnumeric(end_log::text) THEN
|
||||
SELECT jsonb_agg(
|
||||
jsonb_build_object('type', 'Feature',
|
||||
'properties', jsonb_build_object( 'notes', f->'properties'->>'notes'),
|
||||
'geometry', jsonb_build_object( 'coordinates', f->'geometry'->'coordinates', 'type', 'Point'))
|
||||
) INTO _geojson
|
||||
FROM (
|
||||
SELECT jsonb_array_elements(track_geojson->'features') AS f
|
||||
FROM api.logbook
|
||||
WHERE id >= start_log
|
||||
AND id <= end_log
|
||||
AND track_geojson IS NOT NULL
|
||||
ORDER BY _from_time ASC
|
||||
) AS sub
|
||||
WHERE (f->'geometry'->>'type') = 'Point';
|
||||
ELSIF start_date IS NOT NULL AND public.isdate(start_date::text) AND public.isdate(end_date::text) THEN
|
||||
SELECT jsonb_agg(
|
||||
jsonb_build_object('type', 'Feature',
|
||||
'properties', jsonb_build_object( 'notes', f->'properties'->>'notes'),
|
||||
'geometry', jsonb_build_object( 'coordinates', f->'geometry'->'coordinates', 'type', 'Point'))
|
||||
) INTO _geojson
|
||||
FROM (
|
||||
SELECT jsonb_array_elements(track_geojson->'features') AS f
|
||||
FROM api.logbook
|
||||
WHERE _from_time >= start_date::TIMESTAMPTZ
|
||||
AND _to_time <= end_date::TIMESTAMPTZ + interval '23 hours 59 minutes'
|
||||
AND track_geojson IS NOT NULL
|
||||
ORDER BY _from_time ASC
|
||||
) AS sub
|
||||
WHERE (f->'geometry'->>'type') = 'Point';
|
||||
ELSE
|
||||
SELECT jsonb_agg(
|
||||
jsonb_build_object('type', 'Feature',
|
||||
'properties', jsonb_build_object( 'notes', f->'properties'->>'notes'),
|
||||
'geometry', jsonb_build_object( 'coordinates', f->'geometry'->'coordinates', 'type', 'Point'))
|
||||
) INTO _geojson
|
||||
FROM (
|
||||
SELECT jsonb_array_elements(track_geojson->'features') AS f
|
||||
FROM api.logbook
|
||||
WHERE track_geojson IS NOT NULL
|
||||
ORDER BY _from_time ASC
|
||||
) AS sub
|
||||
WHERE (f->'geometry'->>'type') = 'Point';
|
||||
END IF;
|
||||
-- Return a GeoJSON MultiLineString
|
||||
-- result _geojson [null, null]
|
||||
raise WARNING 'result _geojson %' , _geojson;
|
||||
SELECT jsonb_build_object(
|
||||
'type', 'FeatureCollection',
|
||||
'features', _geojson ) INTO geojson;
|
||||
END;
|
||||
$timelapse2$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.timelapse2_fn
|
||||
IS 'Export all selected logs geometry `track_geom` to a geojson as points with notes properties';
|
||||
|
||||
-- export_logbook_geojson_fn
|
||||
DROP FUNCTION IF EXISTS api.export_logbook_geojson_fn;
|
||||
CREATE FUNCTION api.export_logbook_geojson_fn(IN _id integer, OUT geojson JSONB) RETURNS JSONB AS $export_logbook_geojson$
|
||||
-- validate with geojson.io
|
||||
DECLARE
|
||||
logbook_rec record;
|
||||
BEGIN
|
||||
-- If _id is is not NULL and > 0
|
||||
IF _id IS NULL OR _id < 1 THEN
|
||||
RAISE WARNING '-> export_logbook_geojson_fn invalid input %', _id;
|
||||
RETURN;
|
||||
END IF;
|
||||
-- Gather log details
|
||||
SELECT * INTO logbook_rec
|
||||
FROM api.logbook WHERE id = _id;
|
||||
-- Ensure the query is successful
|
||||
IF logbook_rec.vessel_id IS NULL THEN
|
||||
RAISE WARNING '-> export_logbook_geojson_fn invalid logbook %', _id;
|
||||
RETURN;
|
||||
END IF;
|
||||
geojson := logbook_rec.track_geojson;
|
||||
END;
|
||||
$export_logbook_geojson$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.export_logbook_geojson_fn
|
||||
IS 'Export a log entry to geojson with features LineString and Point';
|
||||
|
||||
-- Generate GPX XML file output
|
||||
-- https://opencpn.org/OpenCPN/info/gpxvalidation.html
|
||||
--
|
||||
DROP FUNCTION IF EXISTS api.export_logbook_gpx_fn;
|
||||
CREATE OR REPLACE FUNCTION api.export_logbook_gpx_fn(IN _id INTEGER) RETURNS "text/xml"
|
||||
AS $export_logbook_gpx$
|
||||
DECLARE
|
||||
app_settings jsonb;
|
||||
BEGIN
|
||||
-- If _id is is not NULL and > 0
|
||||
IF _id IS NULL OR _id < 1 THEN
|
||||
RAISE WARNING '-> export_logbook_gpx_fn invalid input %', _id;
|
||||
RETURN '';
|
||||
END IF;
|
||||
-- Gather url from app settings
|
||||
app_settings := get_app_url_fn();
|
||||
--RAISE DEBUG '-> logbook_update_gpx_fn app_settings %', app_settings;
|
||||
-- Generate GPX XML, extract Point features from geojson.
|
||||
RETURN xmlelement(name gpx,
|
||||
xmlattributes( '1.1' as version,
|
||||
'PostgSAIL' as creator,
|
||||
'http://www.topografix.com/GPX/1/1' as xmlns,
|
||||
'http://www.opencpn.org' as "xmlns:opencpn",
|
||||
app_settings->>'app.url' as "xmlns:postgsail",
|
||||
'http://www.w3.org/2001/XMLSchema-instance' as "xmlns:xsi",
|
||||
'http://www.garmin.com/xmlschemas/GpxExtensions/v3' as "xmlns:gpxx",
|
||||
'http://www.topografix.com/GPX/1/1 http://www.topografix.com/GPX/1/1/gpx.xsd http://www.garmin.com/xmlschemas/GpxExtensions/v3 http://www8.garmin.com/xmlschemas/GpxExtensionsv3.xsd' as "xsi:schemaLocation"),
|
||||
xmlelement(name metadata,
|
||||
xmlelement(name link, xmlattributes(app_settings->>'app.url' as href),
|
||||
xmlelement(name text, 'PostgSail'))),
|
||||
xmlelement(name trk,
|
||||
xmlelement(name name, l.name),
|
||||
xmlelement(name desc, l.notes),
|
||||
xmlelement(name link, xmlattributes(concat(app_settings->>'app.url', '/log/', l.id) as href),
|
||||
xmlelement(name text, l.name)),
|
||||
xmlelement(name extensions, xmlelement(name "postgsail:log_id", l.id),
|
||||
xmlelement(name "postgsail:link", concat(app_settings->>'app.url', '/log/', l.id)),
|
||||
xmlelement(name "opencpn:guid", uuid_generate_v4()),
|
||||
xmlelement(name "opencpn:viz", '1'),
|
||||
xmlelement(name "opencpn:start", l._from_time),
|
||||
xmlelement(name "opencpn:end", l._to_time)
|
||||
),
|
||||
xmlelement(name trkseg, xmlagg(
|
||||
xmlelement(name trkpt,
|
||||
xmlattributes(features->'geometry'->'coordinates'->1 as lat, features->'geometry'->'coordinates'->0 as lon),
|
||||
xmlelement(name time, features->'properties'->>'time')
|
||||
)))))::pg_catalog.xml
|
||||
FROM api.logbook l, jsonb_array_elements(track_geojson->'features') AS features
|
||||
WHERE features->'geometry'->>'type' = 'Point'
|
||||
AND l.id = _id
|
||||
GROUP BY l.name,l.notes,l.id;
|
||||
END;
|
||||
$export_logbook_gpx$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.export_logbook_gpx_fn
|
||||
IS 'Export a log entry to GPX XML format';
|
||||
|
||||
-- Generate KML XML file output
|
||||
-- https://developers.google.com/kml/documentation/kml_tut
|
||||
-- TODO https://developers.google.com/kml/documentation/time#timespans
|
||||
DROP FUNCTION IF EXISTS api.export_logbook_kml_fn;
|
||||
CREATE OR REPLACE FUNCTION api.export_logbook_kml_fn(IN _id INTEGER) RETURNS "text/xml"
|
||||
AS $export_logbook_kml$
|
||||
DECLARE
|
||||
logbook_rec record;
|
||||
BEGIN
|
||||
-- If _id is is not NULL and > 0
|
||||
IF _id IS NULL OR _id < 1 THEN
|
||||
RAISE WARNING '-> export_logbook_kml_fn invalid input %', _id;
|
||||
return '';
|
||||
END IF;
|
||||
-- Gather log details
|
||||
SELECT * INTO logbook_rec
|
||||
FROM api.logbook WHERE id = _id;
|
||||
-- Ensure the query is successful
|
||||
IF logbook_rec.vessel_id IS NULL THEN
|
||||
RAISE WARNING '-> export_logbook_kml_fn invalid logbook %', _id;
|
||||
return '';
|
||||
END IF;
|
||||
-- Extract POINT from LINESTRING to generate KML XML
|
||||
RETURN xmlelement(name kml,
|
||||
xmlattributes( '1.0' as version,
|
||||
'PostgSAIL' as creator,
|
||||
'http://www.w3.org/2005/Atom' as "xmlns:atom",
|
||||
'http://www.opengis.net/kml/2.2' as "xmlns",
|
||||
'http://www.google.com/kml/ext/2.2' as "xmlns:gx",
|
||||
'http://www.opengis.net/kml/2.2' as "xmlns:kml"),
|
||||
xmlelement(name "Document",
|
||||
xmlelement(name name, logbook_rec.name),
|
||||
xmlelement(name "Placemark",
|
||||
xmlelement(name name, logbook_rec.notes),
|
||||
ST_AsKML(logbook_rec.track_geom)::pg_catalog.xml)
|
||||
))::pg_catalog.xml
|
||||
FROM api.logbook WHERE id = _id;
|
||||
END;
|
||||
$export_logbook_kml$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.export_logbook_kml_fn
|
||||
IS 'Export a log entry to KML XML format';
|
||||
|
||||
DROP FUNCTION IF EXISTS api.export_logbooks_gpx_fn;
|
||||
CREATE OR REPLACE FUNCTION api.export_logbooks_gpx_fn(
|
||||
IN start_log INTEGER DEFAULT NULL,
|
||||
IN end_log INTEGER DEFAULT NULL) RETURNS "application/gpx+xml"
|
||||
AS $export_logbooks_gpx$
|
||||
declare
|
||||
merged_jsonb jsonb;
|
||||
app_settings jsonb;
|
||||
BEGIN
|
||||
-- Merge GIS track_geom of geometry type Point into a jsonb array format
|
||||
IF start_log IS NOT NULL AND public.isnumeric(start_log::text) AND public.isnumeric(end_log::text) THEN
|
||||
SELECT jsonb_agg(
|
||||
jsonb_build_object('coordinates', f->'geometry'->'coordinates', 'time', f->'properties'->>'time')
|
||||
) INTO merged_jsonb
|
||||
FROM (
|
||||
SELECT jsonb_array_elements(track_geojson->'features') AS f
|
||||
FROM api.logbook
|
||||
WHERE id >= start_log
|
||||
AND id <= end_log
|
||||
AND track_geojson IS NOT NULL
|
||||
ORDER BY _from_time ASC
|
||||
) AS sub
|
||||
WHERE (f->'geometry'->>'type') = 'Point';
|
||||
ELSE
|
||||
SELECT jsonb_agg(
|
||||
jsonb_build_object('coordinates', f->'geometry'->'coordinates', 'time', f->'properties'->>'time')
|
||||
) INTO merged_jsonb
|
||||
FROM (
|
||||
SELECT jsonb_array_elements(track_geojson->'features') AS f
|
||||
FROM api.logbook
|
||||
WHERE track_geojson IS NOT NULL
|
||||
ORDER BY _from_time ASC
|
||||
) AS sub
|
||||
WHERE (f->'geometry'->>'type') = 'Point';
|
||||
END IF;
|
||||
--RAISE WARNING '-> export_logbooks_gpx_fn _jsonb %' , _jsonb;
|
||||
-- Gather url from app settings
|
||||
app_settings := get_app_url_fn();
|
||||
--RAISE WARNING '-> export_logbooks_gpx_fn app_settings %', app_settings;
|
||||
-- Generate GPX XML, extract Point features from geojson.
|
||||
RETURN xmlelement(name gpx,
|
||||
xmlattributes( '1.1' as version,
|
||||
'PostgSAIL' as creator,
|
||||
'http://www.topografix.com/GPX/1/1' as xmlns,
|
||||
'http://www.opencpn.org' as "xmlns:opencpn",
|
||||
app_settings->>'app.url' as "xmlns:postgsail"),
|
||||
xmlelement(name metadata,
|
||||
xmlelement(name link, xmlattributes(app_settings->>'app.url' as href),
|
||||
xmlelement(name text, 'PostgSail'))),
|
||||
xmlelement(name trk,
|
||||
xmlelement(name name, 'logbook name'),
|
||||
xmlelement(name trkseg, xmlagg(
|
||||
xmlelement(name trkpt,
|
||||
xmlattributes(features->'coordinates'->1 as lat, features->'coordinates'->0 as lon),
|
||||
xmlelement(name time, features->'properties'->>'time')
|
||||
)))))::pg_catalog.xml
|
||||
FROM jsonb_array_elements(merged_jsonb) AS features;
|
||||
END;
|
||||
$export_logbooks_gpx$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.export_logbooks_gpx_fn
|
||||
IS 'Export a logs entries to GPX XML format';
|
||||
|
||||
DROP FUNCTION IF EXISTS api.export_logbooks_kml_fn;
|
||||
CREATE OR REPLACE FUNCTION api.export_logbooks_kml_fn(
|
||||
IN start_log INTEGER DEFAULT NULL,
|
||||
IN end_log INTEGER DEFAULT NULL) RETURNS "text/xml"
|
||||
AS $export_logbooks_kml$
|
||||
DECLARE
|
||||
_geom geometry;
|
||||
app_settings jsonb;
|
||||
BEGIN
|
||||
-- Merge GIS track_geom into a GeoJSON MultiLineString
|
||||
IF start_log IS NOT NULL AND public.isnumeric(start_log::text) AND public.isnumeric(end_log::text) THEN
|
||||
WITH logbook as (
|
||||
SELECT track_geom
|
||||
FROM api.logbook
|
||||
WHERE id >= start_log
|
||||
AND id <= end_log
|
||||
AND track_geom IS NOT NULL
|
||||
ORDER BY _from_time ASC
|
||||
)
|
||||
SELECT ST_Collect(
|
||||
ARRAY(
|
||||
SELECT track_geom FROM logbook))
|
||||
into _geom;
|
||||
ELSE
|
||||
WITH logbook as (
|
||||
SELECT track_geom
|
||||
FROM api.logbook
|
||||
WHERE track_geom IS NOT NULL
|
||||
ORDER BY _from_time ASC
|
||||
)
|
||||
SELECT ST_Collect(
|
||||
ARRAY(
|
||||
SELECT track_geom FROM logbook))
|
||||
into _geom;
|
||||
--raise WARNING 'all result _geojson %' , _geojson;
|
||||
END IF;
|
||||
|
||||
-- Extract POINT from LINESTRING to generate KML XML
|
||||
RETURN xmlelement(name kml,
|
||||
xmlattributes( '1.0' as version,
|
||||
'PostgSAIL' as creator,
|
||||
'http://www.w3.org/2005/Atom' as "xmlns:atom",
|
||||
'http://www.opengis.net/kml/2.2' as "xmlns",
|
||||
'http://www.google.com/kml/ext/2.2' as "xmlns:gx",
|
||||
'http://www.opengis.net/kml/2.2' as "xmlns:kml"),
|
||||
xmlelement(name "Document",
|
||||
xmlelement(name name, 'logbook name'),
|
||||
xmlelement(name "Placemark",
|
||||
ST_AsKML(_geom)::pg_catalog.xml
|
||||
)
|
||||
)
|
||||
)::pg_catalog.xml;
|
||||
END;
|
||||
$export_logbooks_kml$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.export_logbooks_kml_fn
|
||||
IS 'Export a logs entries to KML XML format';
|
||||
|
||||
-- Find all log from and to moorage geopoint within 100m
|
||||
DROP FUNCTION IF EXISTS api.find_log_from_moorage_fn;
|
||||
CREATE OR REPLACE FUNCTION api.find_log_from_moorage_fn(IN _id INTEGER, OUT geojson JSONB) RETURNS JSONB AS $find_log_from_moorage$
|
||||
DECLARE
|
||||
moorage_rec record;
|
||||
_geojson jsonb;
|
||||
BEGIN
|
||||
-- If _id is is not NULL and > 0
|
||||
IF _id IS NULL OR _id < 1 THEN
|
||||
RAISE WARNING '-> find_log_from_moorage_fn invalid input %', _id;
|
||||
RETURN;
|
||||
END IF;
|
||||
-- Gather moorage details
|
||||
SELECT * INTO moorage_rec
|
||||
FROM api.moorages m
|
||||
WHERE m.id = _id;
|
||||
-- Find all log from and to moorage geopoint within 100m
|
||||
SELECT jsonb_agg(l.track_geojson->'features') INTO _geojson
|
||||
FROM api.logbook l
|
||||
WHERE ST_DWithin(
|
||||
Geography(ST_MakePoint(l._from_lng, l._from_lat)),
|
||||
moorage_rec.geog,
|
||||
1000 -- in meters ?
|
||||
);
|
||||
-- Return a GeoJSON filter on LineString
|
||||
SELECT jsonb_build_object(
|
||||
'type', 'FeatureCollection',
|
||||
'features', public.geojson_py_fn(_geojson, 'Point'::TEXT) ) INTO geojson;
|
||||
END;
|
||||
$find_log_from_moorage$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.find_log_from_moorage_fn
|
||||
IS 'Find all log from moorage geopoint within 100m';
|
||||
|
||||
DROP FUNCTION IF EXISTS api.find_log_to_moorage_fn;
|
||||
CREATE OR REPLACE FUNCTION api.find_log_to_moorage_fn(IN _id INTEGER, OUT geojson JSONB) RETURNS JSONB AS $find_log_to_moorage$
|
||||
DECLARE
|
||||
moorage_rec record;
|
||||
_geojson jsonb;
|
||||
BEGIN
|
||||
-- If _id is is not NULL and > 0
|
||||
IF _id IS NULL OR _id < 1 THEN
|
||||
RAISE WARNING '-> find_log_from_moorage_fn invalid input %', _id;
|
||||
RETURN;
|
||||
END IF;
|
||||
-- Gather moorage details
|
||||
SELECT * INTO moorage_rec
|
||||
FROM api.moorages m
|
||||
WHERE m.id = _id;
|
||||
-- Find all log from and to moorage geopoint within 100m
|
||||
SELECT jsonb_agg(l.track_geojson->'features') INTO _geojson
|
||||
FROM api.logbook l
|
||||
WHERE ST_DWithin(
|
||||
Geography(ST_MakePoint(l._to_lng, l._to_lat)),
|
||||
moorage_rec.geog,
|
||||
1000 -- in meters ?
|
||||
);
|
||||
-- Return a GeoJSON filter on LineString
|
||||
SELECT jsonb_build_object(
|
||||
'type', 'FeatureCollection',
|
||||
'features', public.geojson_py_fn(_geojson, 'Point'::TEXT) ) INTO geojson;
|
||||
END;
|
||||
$find_log_to_moorage$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.find_log_to_moorage_fn
|
||||
IS 'Find all log to moorage geopoint within 100m';
|
||||
|
||||
-- Find all stay within 100m of moorage geopoint
|
||||
DROP FUNCTION IF EXISTS api.find_stay_from_moorage_fn;
|
||||
CREATE OR REPLACE FUNCTION api.find_stay_from_moorage_fn(IN _id INTEGER) RETURNS void AS $find_stay_from_moorage$
|
||||
DECLARE
|
||||
moorage_rec record;
|
||||
stay_rec record;
|
||||
BEGIN
|
||||
-- If _id is is not NULL and > 0
|
||||
SELECT * INTO moorage_rec
|
||||
FROM api.moorages m
|
||||
WHERE m.id = _id;
|
||||
-- find all log from and to moorage geopoint within 100m
|
||||
--RETURN QUERY
|
||||
SELECT s.id,s.arrived,s.departed,s.duration,sa.description
|
||||
FROM api.stays s, api.stays_at sa
|
||||
WHERE ST_DWithin(
|
||||
s.geog,
|
||||
moorage_rec.geog,
|
||||
100 -- in meters ?
|
||||
)
|
||||
AND departed IS NOT NULL
|
||||
AND s.name IS NOT NULL
|
||||
AND s.stay_code = sa.stay_code
|
||||
ORDER BY s.arrived DESC;
|
||||
END;
|
||||
$find_stay_from_moorage$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.find_stay_from_moorage_fn
|
||||
IS 'Find all stay within 100m of moorage geopoint';
|
||||
|
||||
-- trip_in_progress_fn
|
||||
DROP FUNCTION IF EXISTS public.trip_in_progress_fn;
|
||||
CREATE FUNCTION public.trip_in_progress_fn(IN _vessel_id TEXT) RETURNS INT AS $trip_in_progress$
|
||||
DECLARE
|
||||
logbook_id INT := NULL;
|
||||
BEGIN
|
||||
SELECT id INTO logbook_id
|
||||
FROM api.logbook l
|
||||
WHERE l.vessel_id IS NOT NULL
|
||||
AND l.vessel_id = _vessel_id
|
||||
AND active IS true
|
||||
LIMIT 1;
|
||||
RETURN logbook_id;
|
||||
END;
|
||||
$trip_in_progress$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.trip_in_progress_fn
|
||||
IS 'trip_in_progress';
|
||||
|
||||
-- stay_in_progress_fn
|
||||
DROP FUNCTION IF EXISTS public.stay_in_progress_fn;
|
||||
CREATE FUNCTION public.stay_in_progress_fn(IN _vessel_id TEXT) RETURNS INT AS $stay_in_progress$
|
||||
DECLARE
|
||||
stay_id INT := NULL;
|
||||
BEGIN
|
||||
SELECT id INTO stay_id
|
||||
FROM api.stays s
|
||||
WHERE s.vessel_id IS NOT NULL
|
||||
AND s.vessel_id = _vessel_id
|
||||
AND active IS true
|
||||
LIMIT 1;
|
||||
RETURN stay_id;
|
||||
END;
|
||||
$stay_in_progress$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.stay_in_progress_fn
|
||||
IS 'stay_in_progress';
|
||||
|
||||
-- logs_by_month_fn
|
||||
DROP FUNCTION IF EXISTS api.logs_by_month_fn;
|
||||
CREATE FUNCTION api.logs_by_month_fn(OUT charts JSONB) RETURNS JSONB AS $logs_by_month$
|
||||
DECLARE
|
||||
data JSONB;
|
||||
BEGIN
|
||||
-- Query logs by month
|
||||
SELECT json_object_agg(month,count) INTO data
|
||||
FROM (
|
||||
SELECT
|
||||
to_char(date_trunc('month', _from_time), 'MM') as month,
|
||||
count(*) as count
|
||||
FROM api.logbook
|
||||
GROUP BY month
|
||||
ORDER BY month
|
||||
) AS t;
|
||||
-- Merge jsonb to get all 12 months
|
||||
SELECT '{"01": 0, "02": 0, "03": 0, "04": 0, "05": 0, "06": 0, "07": 0, "08": 0, "09": 0, "10": 0, "11": 0,"12": 0}'::jsonb ||
|
||||
data::jsonb INTO charts;
|
||||
END;
|
||||
$logs_by_month$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.logs_by_month_fn
|
||||
IS 'logbook by month for web charts';
|
||||
|
||||
-- logs_by_day_fn
|
||||
DROP FUNCTION IF EXISTS api.logs_by_day_fn;
|
||||
CREATE FUNCTION api.logs_by_day_fn(OUT charts JSONB) RETURNS JSONB AS $logs_by_day$
|
||||
DECLARE
|
||||
data JSONB;
|
||||
BEGIN
|
||||
-- Query logs by day
|
||||
SELECT json_object_agg(day,count) INTO data
|
||||
FROM (
|
||||
SELECT
|
||||
to_char(date_trunc('day', _from_time), 'D') as day,
|
||||
count(*) as count
|
||||
FROM api.logbook
|
||||
GROUP BY day
|
||||
ORDER BY day
|
||||
) AS t;
|
||||
-- Merge jsonb to get all 7 days
|
||||
SELECT '{"01": 0, "02": 0, "03": 0, "04": 0, "05": 0, "06": 0, "07": 0}'::jsonb ||
|
||||
data::jsonb INTO charts;
|
||||
END;
|
||||
$logs_by_day$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.logs_by_day_fn
|
||||
IS 'logbook by day for web charts';
|
||||
|
||||
-- moorage_geojson_fn
|
||||
DROP FUNCTION IF EXISTS api.export_moorages_geojson_fn;
|
||||
CREATE FUNCTION api.export_moorages_geojson_fn(OUT geojson JSONB) RETURNS JSONB AS $export_moorages_geojson$
|
||||
DECLARE
|
||||
BEGIN
|
||||
SELECT jsonb_build_object(
|
||||
'type', 'FeatureCollection',
|
||||
'features',
|
||||
( SELECT
|
||||
json_agg(ST_AsGeoJSON(m.*)::JSON) as moorages_geojson
|
||||
FROM
|
||||
( SELECT
|
||||
id,name,stay_code,
|
||||
EXTRACT(DAY FROM justify_hours ( stay_duration )) AS Total_Stay,
|
||||
geog
|
||||
FROM api.moorages
|
||||
WHERE geog IS NOT NULL
|
||||
) AS m
|
||||
)
|
||||
) INTO geojson;
|
||||
END;
|
||||
$export_moorages_geojson$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.export_moorages_geojson_fn
|
||||
IS 'Export moorages as geojson';
|
||||
|
||||
DROP FUNCTION IF EXISTS api.export_moorages_gpx_fn;
|
||||
CREATE FUNCTION api.export_moorages_gpx_fn() RETURNS "text/xml" AS $export_moorages_gpx$
|
||||
DECLARE
|
||||
app_settings jsonb;
|
||||
BEGIN
|
||||
-- Gather url from app settings
|
||||
app_settings := get_app_url_fn();
|
||||
-- Generate XML
|
||||
RETURN xmlelement(name gpx,
|
||||
xmlattributes( '1.1' as version,
|
||||
'PostgSAIL' as creator,
|
||||
'http://www.topografix.com/GPX/1/1' as xmlns,
|
||||
'http://www.opencpn.org' as "xmlns:opencpn",
|
||||
app_settings->>'app.url' as "xmlns:postgsail",
|
||||
'http://www.w3.org/2001/XMLSchema-instance' as "xmlns:xsi",
|
||||
'http://www.garmin.com/xmlschemas/GpxExtensions/v3' as "xmlns:gpxx",
|
||||
'http://www.topografix.com/GPX/1/1 http://www.topografix.com/GPX/1/1/gpx.xsd http://www.garmin.com/xmlschemas/GpxExtensions/v3 http://www8.garmin.com/xmlschemas/GpxExtensionsv3.xsd' as "xsi:schemaLocation"),
|
||||
xmlagg(
|
||||
xmlelement(name wpt, xmlattributes(m.latitude as lat, m.longitude as lon),
|
||||
xmlelement(name name, m.name),
|
||||
xmlelement(name time, 'TODO first seen'),
|
||||
xmlelement(name desc,
|
||||
concat('Last Stayed On: ', 'TODO last seen',
|
||||
E'\nTotal Stays: ', m.stay_duration,
|
||||
E'\nTotal Arrivals and Departures: ', m.reference_count,
|
||||
E'\nLink: ', concat(app_settings->>'app.url','/moorage/', m.id)),
|
||||
xmlelement(name "opencpn:guid", uuid_generate_v4())),
|
||||
xmlelement(name sym, 'anchor'),
|
||||
xmlelement(name type, 'WPT'),
|
||||
xmlelement(name link, xmlattributes(concat(app_settings->>'app.url','moorage/', m.id) as href),
|
||||
xmlelement(name text, m.name)),
|
||||
xmlelement(name extensions, xmlelement(name "postgsail:mooorage_id", m.id),
|
||||
xmlelement(name "postgsail:link", concat(app_settings->>'app.url','/moorage/', m.id)),
|
||||
xmlelement(name "opencpn:guid", uuid_generate_v4()),
|
||||
xmlelement(name "opencpn:viz", '1'),
|
||||
xmlelement(name "opencpn:scale_min_max", xmlattributes(true as UseScale, 30000 as ScaleMin, 0 as ScaleMax)
|
||||
))))
|
||||
)::pg_catalog.xml
|
||||
FROM api.moorages m
|
||||
WHERE geog IS NOT NULL;
|
||||
END;
|
||||
$export_moorages_gpx$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.export_moorages_gpx_fn
|
||||
IS 'Export moorages as gpx';
|
||||
|
||||
----------------------------------------------------------------------------------------------
|
||||
-- Statistics
|
||||
DROP FUNCTION IF EXISTS api.stats_logs_fn;
|
||||
CREATE OR REPLACE FUNCTION api.stats_logs_fn(
|
||||
IN start_date TEXT DEFAULT NULL,
|
||||
IN end_date TEXT DEFAULT NULL,
|
||||
OUT stats JSONB) RETURNS JSONB AS $stats_logs$
|
||||
DECLARE
|
||||
_start_date TIMESTAMPTZ DEFAULT '1970-01-01';
|
||||
_end_date TIMESTAMPTZ DEFAULT NOW();
|
||||
BEGIN
|
||||
IF start_date IS NOT NULL AND public.isdate(start_date::text) AND public.isdate(end_date::text) THEN
|
||||
RAISE WARNING '--> stats_fn, filter result stats by date [%]', start_date;
|
||||
_start_date := start_date::TIMESTAMPTZ;
|
||||
_end_date := end_date::TIMESTAMPTZ;
|
||||
END IF;
|
||||
RAISE NOTICE '--> stats_fn, _start_date [%], _end_date [%]', _start_date, _end_date;
|
||||
WITH
|
||||
meta AS (
|
||||
SELECT m.name FROM api.metadata m ),
|
||||
logs_view AS (
|
||||
SELECT *
|
||||
FROM api.logbook l
|
||||
WHERE _from_time >= _start_date::TIMESTAMPTZ
|
||||
AND _to_time <= _end_date::TIMESTAMPTZ + interval '23 hours 59 minutes'
|
||||
),
|
||||
first_date AS (
|
||||
SELECT _from_time as first_date from logs_view ORDER BY first_date ASC LIMIT 1
|
||||
),
|
||||
last_date AS (
|
||||
SELECT _to_time as last_date from logs_view ORDER BY _to_time DESC LIMIT 1
|
||||
),
|
||||
max_speed_id AS (
|
||||
SELECT id FROM logs_view WHERE max_speed = (SELECT max(max_speed) FROM logs_view) ),
|
||||
max_wind_speed_id AS (
|
||||
SELECT id FROM logs_view WHERE max_wind_speed = (SELECT max(max_wind_speed) FROM logs_view)),
|
||||
max_distance_id AS (
|
||||
SELECT id FROM logs_view WHERE distance = (SELECT max(distance) FROM logs_view)),
|
||||
max_duration_id AS (
|
||||
SELECT id FROM logs_view WHERE duration = (SELECT max(duration) FROM logs_view)),
|
||||
logs_stats AS (
|
||||
SELECT
|
||||
count(*) AS count,
|
||||
max(max_speed) AS max_speed,
|
||||
max(max_wind_speed) AS max_wind_speed,
|
||||
max(distance) AS max_distance,
|
||||
sum(distance) AS sum_distance,
|
||||
max(duration) AS max_duration,
|
||||
sum(duration) AS sum_duration
|
||||
FROM logs_view l )
|
||||
--select * from logbook;
|
||||
-- Return a JSON
|
||||
SELECT jsonb_build_object(
|
||||
'name', meta.name,
|
||||
'first_date', first_date.first_date,
|
||||
'last_date', last_date.last_date,
|
||||
'max_speed_id', max_speed_id.id,
|
||||
'max_wind_speed_id', max_wind_speed_id.id,
|
||||
'max_duration_id', max_duration_id.id,
|
||||
'max_distance_id', max_distance_id.id)::jsonb || to_jsonb(logs_stats.*)::jsonb INTO stats
|
||||
FROM max_speed_id, max_wind_speed_id, max_distance_id, max_duration_id,
|
||||
logs_stats, meta, logs_view, first_date, last_date;
|
||||
-- TODO Add moorages
|
||||
END;
|
||||
$stats_logs$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.stats_logs_fn
|
||||
IS 'Logs stats by date';
|
||||
|
||||
DROP FUNCTION IF EXISTS api.stats_stays_fn;
|
||||
CREATE OR REPLACE FUNCTION api.stats_stays_fn(
|
||||
IN start_date TEXT DEFAULT NULL,
|
||||
IN end_date TEXT DEFAULT NULL,
|
||||
OUT stats JSON) RETURNS JSON AS $stats_stays$
|
||||
DECLARE
|
||||
_start_date TIMESTAMPTZ DEFAULT '1970-01-01';
|
||||
_end_date TIMESTAMPTZ DEFAULT NOW();
|
||||
BEGIN
|
||||
IF start_date IS NOT NULL AND public.isdate(start_date::text) AND public.isdate(end_date::text) THEN
|
||||
RAISE NOTICE '--> stats_stays_fn, custom filter result stats by date [%]', start_date;
|
||||
_start_date := start_date::TIMESTAMPTZ;
|
||||
_end_date := end_date::TIMESTAMPTZ;
|
||||
END IF;
|
||||
RAISE NOTICE '--> stats_stays_fn, _start_date [%], _end_date [%]', _start_date, _end_date;
|
||||
WITH
|
||||
moorages_log AS (
|
||||
SELECT s.id as stays_id, m.id as moorages_id, *
|
||||
FROM api.stays s, api.moorages m
|
||||
WHERE arrived >= _start_date::TIMESTAMPTZ
|
||||
AND departed <= _end_date::TIMESTAMPTZ + interval '23 hours 59 minutes'
|
||||
AND s.id = m.stay_id
|
||||
),
|
||||
home_ports AS (
|
||||
select count(*) as home_ports from moorages_log m where home_flag is true
|
||||
),
|
||||
unique_moorage AS (
|
||||
select count(*) as unique_moorage from moorages_log m
|
||||
),
|
||||
time_at_home_ports AS (
|
||||
select sum(m.stay_duration) as time_at_home_ports from moorages_log m where home_flag is true
|
||||
),
|
||||
sum_stay_duration AS (
|
||||
select sum(m.stay_duration) as sum_stay_duration from moorages_log m where home_flag is false
|
||||
),
|
||||
time_spent_away AS (
|
||||
select m.stay_code,sum(m.stay_duration) as stay_duration from api.moorages m where home_flag is false group by m.stay_code order by m.stay_code
|
||||
),
|
||||
time_spent as (
|
||||
select jsonb_agg(t.*) as time_spent_away from time_spent_away t
|
||||
)
|
||||
-- Return a JSON
|
||||
SELECT jsonb_build_object(
|
||||
'home_ports', home_ports.home_ports,
|
||||
'unique_moorage', unique_moorage.unique_moorage,
|
||||
'time_at_home_ports', time_at_home_ports.time_at_home_ports,
|
||||
'sum_stay_duration', sum_stay_duration.sum_stay_duration,
|
||||
'time_spent_away', time_spent.time_spent_away) INTO stats
|
||||
FROM moorages_log, home_ports, unique_moorage,
|
||||
time_at_home_ports, sum_stay_duration, time_spent;
|
||||
-- TODO Add moorages
|
||||
END;
|
||||
$stats_stays$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.stats_stays_fn
|
||||
IS 'Stays/Moorages stats by date';
|
||||
|
||||
DROP FUNCTION IF EXISTS api.delete_logbook_fn;
|
||||
CREATE OR REPLACE FUNCTION api.delete_logbook_fn(IN _id integer) RETURNS BOOLEAN AS $delete_logbook$
|
||||
DECLARE
|
||||
logbook_rec record;
|
||||
previous_stays_id numeric;
|
||||
current_stays_departed text;
|
||||
current_stays_id numeric;
|
||||
current_stays_active boolean;
|
||||
BEGIN
|
||||
-- If _id is not NULL
|
||||
IF _id IS NULL OR _id < 1 THEN
|
||||
RAISE WARNING '-> delete_logbook_fn invalid input %', _id;
|
||||
RETURN FALSE;
|
||||
END IF;
|
||||
SELECT * INTO logbook_rec
|
||||
FROM api.logbook l
|
||||
WHERE id = _id;
|
||||
-- Update logbook
|
||||
UPDATE api.logbook l
|
||||
SET notes = 'mark for deletion'
|
||||
WHERE l.vessel_id = current_setting('vessel.id', false)
|
||||
AND id = logbook_rec.id;
|
||||
-- Update metrics status to moored
|
||||
UPDATE api.metrics
|
||||
SET status = 'moored'
|
||||
WHERE time >= logbook_rec._from_time::TIMESTAMPTZ
|
||||
AND time <= logbook_rec._to_time::TIMESTAMPTZ
|
||||
AND vessel_id = current_setting('vessel.id', false);
|
||||
-- Get related stays
|
||||
SELECT id,departed,active INTO current_stays_id,current_stays_departed,current_stays_active
|
||||
FROM api.stays s
|
||||
WHERE s.vessel_id = current_setting('vessel.id', false)
|
||||
AND s.arrived = logbook_rec._to_time;
|
||||
-- Update related stays
|
||||
UPDATE api.stays s
|
||||
SET notes = 'mark for deletion'
|
||||
WHERE s.vessel_id = current_setting('vessel.id', false)
|
||||
AND s.arrived = logbook_rec._to_time;
|
||||
-- Find previous stays
|
||||
SELECT id INTO previous_stays_id
|
||||
FROM api.stays s
|
||||
WHERE s.vessel_id = current_setting('vessel.id', false)
|
||||
AND s.arrived < logbook_rec._to_time
|
||||
ORDER BY s.arrived DESC LIMIT 1;
|
||||
-- Update previous stays with the departed time from current stays
|
||||
-- and set the active state from current stays
|
||||
UPDATE api.stays
|
||||
SET departed = current_stays_departed::TIMESTAMPTZ,
|
||||
active = current_stays_active
|
||||
WHERE vessel_id = current_setting('vessel.id', false)
|
||||
AND id = previous_stays_id;
|
||||
-- Clean up, remove invalid logbook and stay entry
|
||||
DELETE FROM api.logbook WHERE id = logbook_rec.id;
|
||||
RAISE WARNING '-> delete_logbook_fn delete logbook [%]', logbook_rec.id;
|
||||
DELETE FROM api.stays WHERE id = current_stays_id;
|
||||
RAISE WARNING '-> delete_logbook_fn delete stays [%]', current_stays_id;
|
||||
-- Clean up, Subtract (-1) moorages ref count
|
||||
UPDATE api.moorages
|
||||
SET reference_count = reference_count - 1
|
||||
WHERE vessel_id = current_setting('vessel.id', false)
|
||||
AND id = previous_stays_id;
|
||||
RETURN TRUE;
|
||||
END;
|
||||
$delete_logbook$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.delete_logbook_fn
|
||||
IS 'Delete a logbook and dependency stay';
|
||||
|
||||
CREATE OR REPLACE FUNCTION api.monitoring_history_fn(IN time_interval TEXT DEFAULT '24', OUT history_metrics JSONB) RETURNS JSONB AS $monitoring_history$
|
||||
DECLARE
|
||||
bucket_interval interval := '5 minutes';
|
||||
BEGIN
|
||||
RAISE NOTICE '-> monitoring_history_fn';
|
||||
SELECT CASE time_interval
|
||||
WHEN '24' THEN '5 minutes'
|
||||
WHEN '48' THEN '2 hours'
|
||||
WHEN '72' THEN '4 hours'
|
||||
WHEN '168' THEN '7 hours'
|
||||
ELSE '5 minutes'
|
||||
END bucket INTO bucket_interval;
|
||||
RAISE NOTICE '-> monitoring_history_fn % %', time_interval, bucket_interval;
|
||||
WITH history_table AS (
|
||||
SELECT time_bucket(bucket_interval::INTERVAL, time) AS time_bucket,
|
||||
avg((metrics->'environment.water.temperature')::numeric) AS waterTemperature,
|
||||
avg((metrics->'environment.inside.temperature')::numeric) AS insideTemperature,
|
||||
avg((metrics->'environment.outside.temperature')::numeric) AS outsideTemperature,
|
||||
avg((metrics->'environment.wind.speedOverGround')::numeric) AS windSpeedOverGround,
|
||||
avg((metrics->'environment.inside.relativeHumidity')::numeric) AS insideHumidity,
|
||||
avg((metrics->'environment.outside.relativeHumidity')::numeric) AS outsideHumidity,
|
||||
avg((metrics->'environment.outside.pressure')::numeric) AS outsidePressure,
|
||||
avg((metrics->'environment.inside.pressure')::numeric) AS insidePressure,
|
||||
avg((metrics->'electrical.batteries.House.capacity.stateOfCharge')::numeric) AS batteryCharge,
|
||||
avg((metrics->'electrical.batteries.House.voltage')::numeric) AS batteryVoltage,
|
||||
avg((metrics->'environment.depth.belowTransducer')::numeric) AS depth
|
||||
FROM api.metrics
|
||||
WHERE time > (NOW() AT TIME ZONE 'UTC' - INTERVAL '1 hours' * time_interval::NUMERIC)
|
||||
GROUP BY time_bucket
|
||||
ORDER BY time_bucket asc
|
||||
)
|
||||
SELECT jsonb_agg(history_table) INTO history_metrics FROM history_table;
|
||||
END
|
||||
$monitoring_history$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.monitoring_history_fn
|
||||
IS 'Export metrics from a time period 24h, 48h, 72h, 7d';
|
||||
|
||||
CREATE OR REPLACE FUNCTION api.status_fn(out status jsonb) RETURNS JSONB AS $status_fn$
|
||||
DECLARE
|
||||
in_route BOOLEAN := False;
|
||||
BEGIN
|
||||
RAISE NOTICE '-> status_fn';
|
||||
SELECT EXISTS ( SELECT id
|
||||
FROM api.logbook l
|
||||
WHERE active IS True
|
||||
LIMIT 1
|
||||
) INTO in_route;
|
||||
IF in_route IS True THEN
|
||||
-- In route from <logbook.from_name> arrived at <>
|
||||
SELECT jsonb_build_object('status', sa.description, 'location', m.name, 'departed', l._from_time) INTO status
|
||||
from api.logbook l, api.stays_at sa, api.moorages m
|
||||
where s.stay_code = sa.stay_code AND l._from_moorage_id = m.id AND l.active IS True;
|
||||
ELSE
|
||||
-- At <Stat_at.Desc> in <Moorage.name> departed at <>
|
||||
SELECT jsonb_build_object('status', sa.description, 'location', m.name, 'arrived', s.arrived) INTO status
|
||||
from api.stays s, api.stays_at sa, api.moorages m
|
||||
where s.stay_code = sa.stay_code AND s.moorage_id = m.id AND s.active IS True;
|
||||
END IF;
|
||||
END
|
||||
$status_fn$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.status_fn
|
||||
IS 'generate vessel status';
|
510
initdb/02_1_3_signalk_api_views.sql
Normal file
510
initdb/02_1_3_signalk_api_views.sql
Normal file
@@ -0,0 +1,510 @@
|
||||
|
||||
-- connect to the DB
|
||||
\c signalk
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- API helper views
|
||||
--
|
||||
---------------------------------------------------------------------------
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Views
|
||||
-- Views are invoked with the privileges of the view owner,
|
||||
-- make the user_role the view’s owner.
|
||||
-- to bypass this limit you need pg15+ with specific settings
|
||||
-- security_invoker=true,security_barrier=true
|
||||
---------------------------------------------------------------------------
|
||||
|
||||
CREATE VIEW public.first_metric AS
|
||||
SELECT *
|
||||
FROM api.metrics
|
||||
ORDER BY time ASC LIMIT 1;
|
||||
|
||||
CREATE VIEW public.last_metric AS
|
||||
SELECT *
|
||||
FROM api.metrics
|
||||
ORDER BY time DESC LIMIT 1;
|
||||
|
||||
DROP VIEW IF EXISTS public.trip_in_progress;
|
||||
CREATE VIEW public.trip_in_progress AS
|
||||
SELECT *
|
||||
FROM api.logbook
|
||||
WHERE active IS true;
|
||||
|
||||
DROP VIEW IF EXISTS public.stay_in_progress;
|
||||
CREATE VIEW public.stay_in_progress AS
|
||||
SELECT *
|
||||
FROM api.stays
|
||||
WHERE active IS true;
|
||||
|
||||
-- TODO: Use materialized views instead as it is not live data
|
||||
-- Logs web view
|
||||
DROP VIEW IF EXISTS api.logs_view;
|
||||
CREATE OR REPLACE VIEW api.logs_view WITH (security_invoker=true,security_barrier=true) AS
|
||||
SELECT id,
|
||||
name as "name",
|
||||
_from as "from",
|
||||
_from_time as "started",
|
||||
_to as "to",
|
||||
_to_time as "ended",
|
||||
distance as "distance",
|
||||
duration as "duration",
|
||||
_from_moorage_id,_to_moorage_id
|
||||
FROM api.logbook l
|
||||
WHERE name IS NOT NULL
|
||||
AND _to_time IS NOT NULL
|
||||
ORDER BY _from_time DESC;
|
||||
-- Description
|
||||
COMMENT ON VIEW
|
||||
api.logs_view
|
||||
IS 'Logs web view';
|
||||
|
||||
-- Initial try of MATERIALIZED VIEW - does not support RLS
|
||||
CREATE MATERIALIZED VIEW api.logs_mat_view AS
|
||||
SELECT id,
|
||||
name as "name",
|
||||
_from as "from",
|
||||
_from_time as "started",
|
||||
_to as "to",
|
||||
_to_time as "ended",
|
||||
distance as "distance",
|
||||
duration as "duration",
|
||||
_from_moorage_id,_to_moorage_id
|
||||
FROM api.logbook l
|
||||
WHERE name IS NOT NULL
|
||||
AND _to_time IS NOT NULL
|
||||
ORDER BY _from_time DESC;
|
||||
-- Description
|
||||
COMMENT ON MATERIALIZED VIEW
|
||||
api.logs_mat_view
|
||||
IS 'Logs MATERIALIZED web view';
|
||||
|
||||
DROP VIEW IF EXISTS api.log_view;
|
||||
CREATE OR REPLACE VIEW api.log_view WITH (security_invoker=true,security_barrier=true) AS
|
||||
SELECT id,
|
||||
name as "name",
|
||||
_from as "from",
|
||||
_from_time as "started",
|
||||
_to as "to",
|
||||
_to_time as "ended",
|
||||
distance as "distance",
|
||||
duration as "duration",
|
||||
notes as "notes",
|
||||
track_geojson as geojson,
|
||||
avg_speed as avg_speed,
|
||||
max_speed as max_speed,
|
||||
max_wind_speed as max_wind_speed,
|
||||
extra as extra,
|
||||
_from_moorage_id as from_moorage_id,
|
||||
_to_moorage_id as to_moorage_id
|
||||
FROM api.logbook l
|
||||
WHERE _to_time IS NOT NULL
|
||||
ORDER BY _from_time DESC;
|
||||
-- Description
|
||||
COMMENT ON VIEW
|
||||
api.log_view
|
||||
IS 'Log web view';
|
||||
|
||||
-- Stays web view
|
||||
DROP VIEW IF EXISTS api.stays_view;
|
||||
CREATE OR REPLACE VIEW api.stays_view WITH (security_invoker=true,security_barrier=true) AS
|
||||
SELECT s.id,
|
||||
s.name AS "name",
|
||||
m.name AS "moorage",
|
||||
m.id AS "moorage_id",
|
||||
(s.departed-s.arrived) AS "duration",
|
||||
sa.description AS "stayed_at",
|
||||
sa.stay_code AS "stayed_at_id",
|
||||
s.arrived AS "arrived",
|
||||
_from.id as "arrived_log_id",
|
||||
_from._to_moorage_id as "arrived_from_moorage_id",
|
||||
_from._to as "arrived_from_moorage_name",
|
||||
s.departed AS "departed",
|
||||
_to.id AS "departed_log_id",
|
||||
_to._from_moorage_id AS "departed_to_moorage_id",
|
||||
_to._from AS "departed_to_moorage_name",
|
||||
s.notes AS "notes"
|
||||
FROM api.stays_at sa, api.moorages m, api.stays s
|
||||
LEFT JOIN api.logbook AS _from ON _from._from_time = s.departed
|
||||
LEFT JOIN api.logbook AS _to ON _to._to_time = s.arrived
|
||||
WHERE s.departed IS NOT NULL
|
||||
AND _from._to_moorage_id IS NOT NULL
|
||||
AND s.name IS NOT NULL
|
||||
AND s.stay_code = sa.stay_code
|
||||
AND s.moorage_id = m.id
|
||||
ORDER BY s.arrived DESC;
|
||||
-- Description
|
||||
COMMENT ON VIEW
|
||||
api.stays_view
|
||||
IS 'Stays web view';
|
||||
|
||||
DROP VIEW IF EXISTS api.stay_view;
|
||||
CREATE OR REPLACE VIEW api.stay_view WITH (security_invoker=true,security_barrier=true) AS
|
||||
SELECT s.id,
|
||||
s.name AS "name",
|
||||
m.name AS "moorage",
|
||||
m.id AS "moorage_id",
|
||||
(s.departed-s.arrived) AS "duration",
|
||||
sa.description AS "stayed_at",
|
||||
sa.stay_code AS "stayed_at_id",
|
||||
s.arrived AS "arrived",
|
||||
_from.id as "arrived_log_id",
|
||||
_from._to_moorage_id as "arrived_from_moorage_id",
|
||||
_from._to as "arrived_from_moorage_name",
|
||||
s.departed AS "departed",
|
||||
_to.id AS "departed_log_id",
|
||||
_to._from_moorage_id AS "departed_to_moorage_id",
|
||||
_to._from AS "departed_to_moorage_name",
|
||||
s.notes AS "notes"
|
||||
FROM api.stays_at sa, api.moorages m, api.stays s
|
||||
LEFT JOIN api.logbook AS _from ON _from._from_time = s.departed
|
||||
LEFT JOIN api.logbook AS _to ON _to._to_time = s.arrived
|
||||
WHERE s.departed IS NOT NULL
|
||||
AND _from._to_moorage_id IS NOT NULL
|
||||
AND s.name IS NOT NULL
|
||||
AND s.stay_code = sa.stay_code
|
||||
AND s.moorage_id = m.id
|
||||
ORDER BY s.arrived DESC;
|
||||
-- Description
|
||||
COMMENT ON VIEW
|
||||
api.stay_view
|
||||
IS 'Stay web view';
|
||||
|
||||
-- Moorages web view
|
||||
-- TODO, this is wrong using distinct (m.name) should be using postgis geog feature
|
||||
--DROP VIEW IF EXISTS api.moorages_view_old;
|
||||
--CREATE VIEW api.moorages_view_old AS
|
||||
-- SELECT
|
||||
-- m.name AS Moorage,
|
||||
-- sa.description AS "Default Stay",
|
||||
-- sum((m.departed-m.arrived)) OVER (PARTITION by m.name) AS "Total Stay",
|
||||
-- count(m.departed) OVER (PARTITION by m.name) AS "Arrivals & Departures"
|
||||
-- FROM api.moorages m, api.stays_at sa
|
||||
-- WHERE departed is not null
|
||||
-- AND m.name is not null
|
||||
-- AND m.stay_code = sa.stay_code
|
||||
-- GROUP BY m.name,sa.description,m.departed,m.arrived
|
||||
-- ORDER BY 4 DESC;
|
||||
|
||||
-- the good way?
|
||||
DROP VIEW IF EXISTS api.moorages_view;
|
||||
CREATE OR REPLACE VIEW api.moorages_view WITH (security_invoker=true,security_barrier=true) AS -- TODO
|
||||
SELECT m.id,
|
||||
m.name AS Moorage,
|
||||
sa.description AS Default_Stay,
|
||||
sa.stay_code AS Default_Stay_Id,
|
||||
EXTRACT(DAY FROM justify_hours ( m.stay_duration )) AS Total_Stay, -- in days
|
||||
m.stay_duration AS Total_Duration,
|
||||
m.reference_count AS Arrivals_Departures
|
||||
-- m.geog
|
||||
-- m.stay_duration,
|
||||
-- justify_hours ( m.stay_duration )
|
||||
FROM api.moorages m, api.stays_at sa
|
||||
-- m.stay_duration is only process on a stay
|
||||
WHERE m.stay_duration IS NOT NULL
|
||||
AND m.geog IS NOT NULL
|
||||
AND m.stay_code = sa.stay_code
|
||||
GROUP BY m.id,m.name,sa.description,m.stay_duration,m.reference_count,m.geog,sa.stay_code
|
||||
-- ORDER BY 4 DESC;
|
||||
-- ORDER BY m.reference_count DESC;
|
||||
ORDER BY m.stay_duration DESC;
|
||||
-- Description
|
||||
COMMENT ON VIEW
|
||||
api.moorages_view
|
||||
IS 'Moorages listing web view';
|
||||
|
||||
DROP VIEW IF EXISTS api.moorage_view;
|
||||
CREATE OR REPLACE VIEW api.moorage_view WITH (security_invoker=true,security_barrier=true) AS -- TODO
|
||||
SELECT id,
|
||||
m.name AS Name,
|
||||
sa.description AS Default_Stay,
|
||||
sa.stay_code AS Default_Stay_Id,
|
||||
m.home_flag AS Home,
|
||||
EXTRACT(DAY FROM justify_hours ( m.stay_duration )) AS Total_Stay,
|
||||
m.stay_duration AS Total_Duration,
|
||||
m.reference_count AS Arrivals_Departures,
|
||||
m.notes
|
||||
-- m.geog
|
||||
FROM api.moorages m, api.stays_at sa
|
||||
-- m.stay_duration is only process on a stay
|
||||
WHERE m.stay_duration IS NOT NULL
|
||||
AND geog IS NOT NULL
|
||||
AND m.stay_code = sa.stay_code;
|
||||
-- Description
|
||||
COMMENT ON VIEW
|
||||
api.moorage_view
|
||||
IS 'Moorage details web view';
|
||||
|
||||
DROP VIEW IF EXISTS api.moorages_stays_view;
|
||||
CREATE OR REPLACE VIEW api.moorages_stays_view WITH (security_invoker=true,security_barrier=true) AS
|
||||
SELECT
|
||||
_to.id AS _to_id,
|
||||
_to._to_time,
|
||||
_from.id AS _from_id,
|
||||
_from._from_time,
|
||||
s.stay_code,s.duration,m.id
|
||||
FROM api.stays_at sa, api.moorages m, api.stays s
|
||||
LEFT JOIN api.logbook AS _from ON _from._from_time = s.departed
|
||||
LEFT JOIN api.logbook AS _to ON _to._to_time = s.arrived
|
||||
WHERE s.departed IS NOT NULL
|
||||
AND s.name IS NOT NULL
|
||||
AND s.stay_code = sa.stay_code
|
||||
AND s.moorage_id = m.id
|
||||
ORDER BY _to._to_time DESC;
|
||||
-- Description
|
||||
COMMENT ON VIEW
|
||||
api.moorages_stays_view
|
||||
IS 'Moorages stay listing web view';
|
||||
|
||||
-- All moorage in 100 meters from the start of a logbook.
|
||||
-- ST_DistanceSphere Returns minimum distance in meters between two lon/lat points.
|
||||
--SELECT
|
||||
-- m.name, ST_MakePoint(m._lng,m._lat),
|
||||
-- l._from, ST_MakePoint(l._from_lng,l._from_lat),
|
||||
-- ST_DistanceSphere(ST_MakePoint(m._lng,m._lat), ST_MakePoint(l._from_lng,l._from_lat))
|
||||
-- FROM api.moorages m , api.logbook l
|
||||
-- WHERE ST_DistanceSphere(ST_MakePoint(m._lng,m._lat), ST_MakePoint(l._from_lng,l._from_lat)) <= 100;
|
||||
|
||||
-- Stats web view
|
||||
-- TODO....
|
||||
-- first time entry from metrics
|
||||
----> select * from api.metrics m ORDER BY m.time desc limit 1
|
||||
-- last time entry from metrics
|
||||
----> select * from api.metrics m ORDER BY m.time asc limit 1
|
||||
-- max speed from logbook
|
||||
-- max wind speed from logbook
|
||||
----> select max(l.max_speed) as max_speed, max(l.max_wind_speed) as max_wind_speed from api.logbook l;
|
||||
-- Total Distance from logbook
|
||||
----> select sum(l.distance) as "Total Distance" from api.logbook l;
|
||||
-- Total Time Underway from logbook
|
||||
----> select sum(l.duration) as "Total Time Underway" from api.logbook l;
|
||||
-- Longest Nonstop Sail from logbook, eg longest trip duration and distance
|
||||
----> select max(l.duration),max(l.distance) from api.logbook l;
|
||||
CREATE OR REPLACE VIEW api.stats_logs_view WITH (security_invoker=true,security_barrier=true) AS -- TODO
|
||||
WITH
|
||||
meta AS (
|
||||
SELECT m.name FROM api.metadata m ),
|
||||
last_metric AS (
|
||||
SELECT m.time FROM api.metrics m ORDER BY m.time DESC limit 1),
|
||||
first_metric AS (
|
||||
SELECT m.time FROM api.metrics m ORDER BY m.time ASC limit 1),
|
||||
logbook AS (
|
||||
SELECT
|
||||
count(*) AS "number_of_log_entries",
|
||||
max(l.max_speed) AS "max_speed",
|
||||
max(l.max_wind_speed) AS "max_wind_speed",
|
||||
sum(l.distance) AS "total_distance",
|
||||
sum(l.duration) AS "total_time_underway",
|
||||
concat( max(l.distance), ' NM, ', max(l.duration), ' hours') AS "longest_nonstop_sail"
|
||||
FROM api.logbook l)
|
||||
SELECT
|
||||
m.name AS name,
|
||||
fm.time AS first,
|
||||
lm.time AS last,
|
||||
l.*
|
||||
FROM first_metric fm, last_metric lm, logbook l, meta m;
|
||||
COMMENT ON VIEW
|
||||
api.stats_logs_view
|
||||
IS 'Statistics Logs web view';
|
||||
|
||||
-- Home Ports / Unique Moorages
|
||||
----> select count(*) as "Home Ports" from api.moorages m where home_flag is true;
|
||||
-- Unique Moorages
|
||||
----> select count(*) as "Home Ports" from api.moorages m;
|
||||
-- Time Spent at Home Port(s)
|
||||
----> select sum(m.stay_duration) as "Time Spent at Home Port(s)" from api.moorages m where home_flag is true;
|
||||
-- OR
|
||||
----> select m.stay_duration as "Time Spent at Home Port(s)" from api.moorages m where home_flag is true;
|
||||
-- Time Spent Away
|
||||
----> select sum(m.stay_duration) as "Time Spent Away" from api.moorages m where home_flag is false;
|
||||
-- Time Spent Away order by, group by stay_code (Dock, Anchor, Mooring Buoys, Unclassified)
|
||||
----> select sa.description,sum(m.stay_duration) as "Time Spent Away" from api.moorages m, api.stays_at sa where home_flag is false AND m.stay_code = sa.stay_code group by m.stay_code,sa.description order by m.stay_code;
|
||||
CREATE OR REPLACE VIEW api.stats_moorages_view WITH (security_invoker=true,security_barrier=true) AS -- TODO
|
||||
WITH
|
||||
home_ports AS (
|
||||
select count(*) as home_ports from api.moorages m where home_flag is true
|
||||
),
|
||||
unique_moorage AS (
|
||||
select count(*) as unique_moorage from api.moorages m
|
||||
),
|
||||
time_at_home_ports AS (
|
||||
select sum(m.stay_duration) as time_at_home_ports from api.moorages m where home_flag is true
|
||||
),
|
||||
time_spent_away AS (
|
||||
select sum(m.stay_duration) as time_spent_away from api.moorages m where home_flag is false
|
||||
)
|
||||
SELECT
|
||||
home_ports.home_ports as "home_ports",
|
||||
unique_moorage.unique_moorage as "unique_moorages",
|
||||
time_at_home_ports.time_at_home_ports "time_spent_at_home_port(s)",
|
||||
time_spent_away.time_spent_away as "time_spent_away"
|
||||
FROM home_ports, unique_moorage, time_at_home_ports, time_spent_away;
|
||||
COMMENT ON VIEW
|
||||
api.stats_moorages_view
|
||||
IS 'Statistics Moorages web view';
|
||||
|
||||
CREATE OR REPLACE VIEW api.stats_moorages_away_view WITH (security_invoker=true,security_barrier=true) AS -- TODO
|
||||
SELECT sa.description,sum(m.stay_duration) as time_spent_away_by
|
||||
FROM api.moorages m, api.stays_at sa
|
||||
WHERE home_flag IS false
|
||||
AND m.stay_code = sa.stay_code
|
||||
GROUP BY m.stay_code,sa.description
|
||||
ORDER BY m.stay_code;
|
||||
COMMENT ON VIEW
|
||||
api.stats_moorages_away_view
|
||||
IS 'Statistics Moorages Time Spent Away web view';
|
||||
|
||||
--CREATE VIEW api.stats_view AS -- todo
|
||||
-- WITH
|
||||
-- logs AS (
|
||||
-- SELECT * FROM api.stats_logs_view ),
|
||||
-- moorages AS (
|
||||
-- SELECT * FROM api.stats_moorages_view)
|
||||
-- SELECT
|
||||
-- l.*,
|
||||
-- m.*
|
||||
-- FROM logs l, moorages m;
|
||||
--COMMENT ON VIEW
|
||||
-- api.stats_moorages_away_view
|
||||
-- IS 'Statistics Moorages Time Spent Away web view';
|
||||
|
||||
-- View main monitoring for web app
|
||||
DROP VIEW IF EXISTS api.monitoring_view;
|
||||
CREATE VIEW api.monitoring_view WITH (security_invoker=true,security_barrier=true) AS
|
||||
SELECT
|
||||
time AS "time",
|
||||
(NOW() AT TIME ZONE 'UTC' - time) > INTERVAL '70 MINUTES' as offline,
|
||||
metrics-> 'environment.water.temperature' AS waterTemperature,
|
||||
metrics-> 'environment.inside.temperature' AS insideTemperature,
|
||||
metrics-> 'environment.outside.temperature' AS outsideTemperature,
|
||||
metrics-> 'environment.wind.speedOverGround' AS windSpeedOverGround,
|
||||
metrics-> 'environment.wind.directionTrue' AS windDirectionTrue,
|
||||
metrics-> 'environment.inside.relativeHumidity' AS insideHumidity,
|
||||
metrics-> 'environment.outside.relativeHumidity' AS outsideHumidity,
|
||||
metrics-> 'environment.outside.pressure' AS outsidePressure,
|
||||
metrics-> 'environment.inside.pressure' AS insidePressure,
|
||||
metrics-> 'electrical.batteries.House.capacity.stateOfCharge' AS batteryCharge,
|
||||
metrics-> 'electrical.batteries.House.voltage' AS batteryVoltage,
|
||||
metrics-> 'environment.depth.belowTransducer' AS depth,
|
||||
jsonb_build_object(
|
||||
'type', 'Feature',
|
||||
'geometry', ST_AsGeoJSON(st_makepoint(longitude,latitude))::jsonb,
|
||||
'properties', jsonb_build_object(
|
||||
'name', current_setting('vessel.name', false),
|
||||
'latitude', m.latitude,
|
||||
'longitude', m.longitude,
|
||||
'time', m.time,
|
||||
'speedoverground', m.speedoverground,
|
||||
'windspeedapparent', m.windspeedapparent
|
||||
)::jsonb ) AS geojson,
|
||||
current_setting('vessel.name', false) AS name
|
||||
--( SELECT api.status_fn() ) AS status
|
||||
FROM api.metrics m
|
||||
ORDER BY time DESC LIMIT 1;
|
||||
COMMENT ON VIEW
|
||||
api.monitoring_view
|
||||
IS 'Monitoring static web view';
|
||||
|
||||
DROP VIEW IF EXISTS api.monitoring_humidity;
|
||||
CREATE VIEW api.monitoring_humidity WITH (security_invoker=true,security_barrier=true) AS
|
||||
SELECT m.time, key, value
|
||||
FROM api.metrics m,
|
||||
jsonb_each_text(m.metrics)
|
||||
WHERE key ILIKE 'environment.%.humidity' OR key ILIKE 'environment.%.relativeHumidity'
|
||||
ORDER BY m.time DESC;
|
||||
COMMENT ON VIEW
|
||||
api.monitoring_humidity
|
||||
IS 'Monitoring environment.%.humidity web view';
|
||||
|
||||
-- View System RPI monitoring for grafana
|
||||
-- View Electric monitoring for grafana
|
||||
|
||||
-- View main monitoring for grafana
|
||||
-- LAST Monitoring data from json!
|
||||
DROP VIEW IF EXISTS api.monitoring_temperatures;
|
||||
CREATE VIEW api.monitoring_temperatures WITH (security_invoker=true,security_barrier=true) AS
|
||||
SELECT m.time, key, value
|
||||
FROM api.metrics m,
|
||||
jsonb_each_text(m.metrics)
|
||||
WHERE key ILIKE 'environment.%.temperature'
|
||||
ORDER BY m.time DESC;
|
||||
COMMENT ON VIEW
|
||||
api.monitoring_temperatures
|
||||
IS 'Monitoring environment.%.temperature web view';
|
||||
|
||||
-- json key regexp
|
||||
-- https://stackoverflow.com/questions/38204467/selecting-for-a-jsonb-array-contains-regex-match
|
||||
-- Last voltage data from json!
|
||||
DROP VIEW IF EXISTS api.monitoring_voltage;
|
||||
CREATE VIEW api.monitoring_voltage WITH (security_invoker=true,security_barrier=true) AS
|
||||
SELECT m.time, key, value
|
||||
FROM api.metrics m,
|
||||
jsonb_each_text(m.metrics)
|
||||
WHERE key ILIKE 'electrical.%.voltage'
|
||||
ORDER BY m.time DESC;
|
||||
COMMENT ON VIEW
|
||||
api.monitoring_voltage
|
||||
IS 'Monitoring electrical.%.voltage web view';
|
||||
|
||||
-- Last whatever data from json!
|
||||
DROP VIEW IF EXISTS api.monitoring_view2;
|
||||
CREATE VIEW api.monitoring_view2 WITH (security_invoker=true,security_barrier=true) AS
|
||||
SELECT
|
||||
*
|
||||
FROM
|
||||
jsonb_each(
|
||||
( SELECT metrics FROM api.metrics m ORDER BY time DESC LIMIT 1)
|
||||
);
|
||||
-- WHERE key ilike 'tanks.%.capacity%'
|
||||
-- or key ilike 'electrical.solar.%.panelPower'
|
||||
-- or key ilike 'electrical.batteries%stateOfCharge'
|
||||
-- or key ilike 'tanks\.%currentLevel'
|
||||
COMMENT ON VIEW
|
||||
api.monitoring_view2
|
||||
IS 'Monitoring Last whatever data from json web view';
|
||||
|
||||
-- Timeseries whatever data from json!
|
||||
DROP VIEW IF EXISTS api.monitoring_view3;
|
||||
CREATE VIEW api.monitoring_view3 WITH (security_invoker=true,security_barrier=true) AS
|
||||
SELECT m.time, key, value
|
||||
FROM api.metrics m,
|
||||
jsonb_each_text(m.metrics)
|
||||
ORDER BY m.time DESC;
|
||||
-- WHERE key ILIKE 'electrical.batteries%voltage';
|
||||
-- WHERE key ilike 'tanks.%.capacity%'
|
||||
-- or key ilike 'electrical.solar.%.panelPower'
|
||||
-- or key ilike 'electrical.batteries%stateOfCharge';
|
||||
-- key ILIKE 'propulsion.%.runTime'
|
||||
-- key ILIKE 'navigation.log'
|
||||
COMMENT ON VIEW
|
||||
api.monitoring_view3
|
||||
IS 'Monitoring Timeseries whatever data from json web view';
|
||||
|
||||
-- Infotiles web app
|
||||
DROP VIEW IF EXISTS api.total_info_view;
|
||||
CREATE VIEW api.total_info_view WITH (security_invoker=true,security_barrier=true) AS
|
||||
-- Infotiles web app, not used calculated client side
|
||||
WITH
|
||||
l as (SELECT count(*) as logs FROM api.logbook),
|
||||
s as (SELECT count(*) as stays FROM api.stays),
|
||||
m as (SELECT count(*) as moorages FROM api.moorages)
|
||||
SELECT * FROM l,s,m;
|
||||
COMMENT ON VIEW
|
||||
api.total_info_view
|
||||
IS 'total_info_view web view';
|
||||
|
||||
DROP VIEW IF EXISTS api.explore_view;
|
||||
CREATE VIEW api.explore_view WITH (security_invoker=true,security_barrier=true) AS
|
||||
-- Expose last metrics
|
||||
WITH raw_metrics AS (
|
||||
SELECT m.time, m.metrics
|
||||
FROM api.metrics m
|
||||
ORDER BY m.time desc limit 1
|
||||
)
|
||||
SELECT raw_metrics.time, key, value
|
||||
FROM raw_metrics,
|
||||
jsonb_each_text(raw_metrics.metrics)
|
||||
ORDER BY key ASC;
|
||||
COMMENT ON VIEW
|
||||
api.explore_view
|
||||
IS 'explore_view web view';
|
992
initdb/02_2_signalk_cron.sql
Normal file
992
initdb/02_2_signalk_cron.sql
Normal file
@@ -0,0 +1,992 @@
|
||||
---------------------------------------------------------------------------
|
||||
-- cron job function helpers on public schema
|
||||
--
|
||||
|
||||
-- List current database
|
||||
select current_database();
|
||||
|
||||
-- connect to the DB
|
||||
\c signalk
|
||||
|
||||
-- Check for new logbook pending validation
|
||||
CREATE FUNCTION cron_process_pre_logbook_fn() RETURNS void AS $$
|
||||
DECLARE
|
||||
process_rec record;
|
||||
BEGIN
|
||||
-- Check for new logbook pending update
|
||||
RAISE NOTICE 'cron_process_pre_logbook_fn init loop';
|
||||
FOR process_rec in
|
||||
SELECT * FROM process_queue
|
||||
WHERE channel = 'pre_logbook' AND processed IS NULL
|
||||
ORDER BY stored ASC LIMIT 100
|
||||
LOOP
|
||||
RAISE NOTICE 'cron_process_pre_logbook_fn processing queue [%] for logbook id [%]', process_rec.id, process_rec.payload;
|
||||
-- update logbook
|
||||
PERFORM process_pre_logbook_fn(process_rec.payload::INTEGER);
|
||||
-- update process_queue table , processed
|
||||
UPDATE process_queue
|
||||
SET
|
||||
processed = NOW()
|
||||
WHERE id = process_rec.id;
|
||||
RAISE NOTICE 'cron_process_pre_logbook_fn processed queue [%] for logbook id [%]', process_rec.id, process_rec.payload;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_process_pre_logbook_fn
|
||||
IS 'init by pg_cron to check for new logbook pending update, if so perform process_logbook_valid_fn';
|
||||
|
||||
|
||||
-- Check for new logbook pending update
|
||||
CREATE FUNCTION cron_process_new_logbook_fn() RETURNS void AS $$
|
||||
declare
|
||||
process_rec record;
|
||||
begin
|
||||
-- Check for new logbook pending update
|
||||
RAISE NOTICE 'cron_process_new_logbook_fn init loop';
|
||||
FOR process_rec in
|
||||
SELECT * FROM process_queue
|
||||
WHERE channel = 'new_logbook' AND processed IS NULL
|
||||
ORDER BY stored ASC LIMIT 100
|
||||
LOOP
|
||||
RAISE NOTICE 'cron_process_new_logbook_fn processing queue [%] for logbook id [%]', process_rec.id, process_rec.payload;
|
||||
-- update logbook
|
||||
PERFORM process_logbook_queue_fn(process_rec.payload::INTEGER);
|
||||
-- update process_queue table , processed
|
||||
UPDATE process_queue
|
||||
SET
|
||||
processed = NOW()
|
||||
WHERE id = process_rec.id;
|
||||
RAISE NOTICE 'cron_process_new_logbook_fn processed queue [%] for logbook id [%]', process_rec.id, process_rec.payload;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_process_new_logbook_fn
|
||||
IS 'init by pg_cron to check for new logbook pending update, if so perform process_logbook_queue_fn';
|
||||
|
||||
-- Check for new stay pending update
|
||||
CREATE FUNCTION cron_process_new_stay_fn() RETURNS void AS $$
|
||||
declare
|
||||
process_rec record;
|
||||
begin
|
||||
-- Check for new stay pending update
|
||||
RAISE NOTICE 'cron_process_new_stay_fn init loop';
|
||||
FOR process_rec in
|
||||
SELECT * FROM process_queue
|
||||
WHERE channel = 'new_stay' AND processed IS NULL
|
||||
ORDER BY stored ASC LIMIT 100
|
||||
LOOP
|
||||
RAISE NOTICE 'cron_process_new_stay_fn processing queue [%] for stay id [%]', process_rec.id, process_rec.payload;
|
||||
-- update stay
|
||||
PERFORM process_stay_queue_fn(process_rec.payload::INTEGER);
|
||||
-- update process_queue table , processed
|
||||
UPDATE process_queue
|
||||
SET
|
||||
processed = NOW()
|
||||
WHERE id = process_rec.id;
|
||||
RAISE NOTICE 'cron_process_new_stay_fn processed queue [%] for stay id [%]', process_rec.id, process_rec.payload;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_process_new_stay_fn
|
||||
IS 'init by pg_cron to check for new stay pending update, if so perform process_stay_queue_fn';
|
||||
|
||||
-- Check for new moorage pending update
|
||||
DROP FUNCTION IF EXISTS cron_process_new_moorage_fn;
|
||||
CREATE OR REPLACE FUNCTION cron_process_new_moorage_fn() RETURNS void AS $$
|
||||
declare
|
||||
process_rec record;
|
||||
begin
|
||||
-- Check for new moorage pending update
|
||||
RAISE NOTICE 'cron_process_new_moorage_fn init loop';
|
||||
FOR process_rec in
|
||||
SELECT * FROM process_queue
|
||||
WHERE channel = 'new_moorage' AND processed IS NULL
|
||||
ORDER BY stored ASC LIMIT 100
|
||||
LOOP
|
||||
RAISE NOTICE 'cron_process_new_moorage_fn processing queue [%] for moorage id [%]', process_rec.id, process_rec.payload;
|
||||
-- update moorage
|
||||
PERFORM process_moorage_queue_fn(process_rec.payload::INTEGER);
|
||||
-- update process_queue table , processed
|
||||
UPDATE process_queue
|
||||
SET
|
||||
processed = NOW()
|
||||
WHERE id = process_rec.id;
|
||||
RAISE NOTICE 'cron_process_new_moorage_fn processed queue [%] for moorage id [%]', process_rec.id, process_rec.payload;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_process_new_moorage_fn
|
||||
IS 'Deprecated, init by pg_cron to check for new moorage pending update, if so perform process_moorage_queue_fn';
|
||||
|
||||
-- CRON Monitor offline pending notification
|
||||
create function cron_process_monitor_offline_fn() RETURNS void AS $$
|
||||
declare
|
||||
metadata_rec record;
|
||||
process_id integer;
|
||||
user_settings jsonb;
|
||||
app_settings jsonb;
|
||||
begin
|
||||
-- Check metadata last_update > 1h + cron_time(10m)
|
||||
RAISE NOTICE 'cron_process_monitor_offline_fn';
|
||||
FOR metadata_rec in
|
||||
SELECT
|
||||
*,
|
||||
NOW() AT TIME ZONE 'UTC' as now,
|
||||
NOW() AT TIME ZONE 'UTC' - INTERVAL '70 MINUTES' as interval
|
||||
FROM api.metadata m
|
||||
WHERE
|
||||
m.time < NOW() AT TIME ZONE 'UTC' - INTERVAL '70 MINUTES'
|
||||
AND active = True
|
||||
ORDER BY m.time desc
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_process_monitor_offline_fn metadata_id [%]', metadata_rec.id;
|
||||
-- update api.metadata table, set active to bool false
|
||||
UPDATE api.metadata
|
||||
SET
|
||||
active = False
|
||||
WHERE id = metadata_rec.id;
|
||||
|
||||
IF metadata_rec.vessel_id IS NULL OR metadata_rec.vessel_id = '' THEN
|
||||
RAISE WARNING '-> cron_process_monitor_offline_fn invalid metadata record vessel_id %', vessel_id;
|
||||
RAISE EXCEPTION 'Invalid metadata'
|
||||
USING HINT = 'Unknown vessel_id';
|
||||
RETURN;
|
||||
END IF;
|
||||
PERFORM set_config('vessel.id', metadata_rec.vessel_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.vessel_id;
|
||||
|
||||
-- Gather email and pushover app settings
|
||||
--app_settings = get_app_settings_fn();
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(metadata_rec.vessel_id::TEXT);
|
||||
RAISE DEBUG '-> cron_process_monitor_offline_fn get_user_settings_from_vesselid_fn [%]', user_settings;
|
||||
-- Send notification
|
||||
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_pushover_py_fn('monitor_offline'::TEXT, user_settings::JSONB, app_settings::JSONB);
|
||||
-- log/insert/update process_queue table with processed
|
||||
INSERT INTO process_queue
|
||||
(channel, payload, stored, processed, ref_id)
|
||||
VALUES
|
||||
('monitoring_offline', metadata_rec.id, metadata_rec.interval, now(), metadata_rec.vessel_id)
|
||||
RETURNING id INTO process_id;
|
||||
RAISE NOTICE '-> cron_process_monitor_offline_fn updated process_queue table [%]', process_id;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_process_monitor_offline_fn
|
||||
IS 'init by pg_cron to monitor offline pending notification, if so perform send_email o send_pushover base on user preferences';
|
||||
|
||||
-- CRON for monitor back online pending notification
|
||||
DROP FUNCTION IF EXISTS cron_process_monitor_online_fn;
|
||||
CREATE FUNCTION cron_process_monitor_online_fn() RETURNS void AS $$
|
||||
declare
|
||||
process_rec record;
|
||||
metadata_rec record;
|
||||
user_settings jsonb;
|
||||
app_settings jsonb;
|
||||
begin
|
||||
-- Check for monitor online pending notification
|
||||
RAISE NOTICE 'cron_process_monitor_online_fn';
|
||||
FOR process_rec in
|
||||
SELECT * from process_queue
|
||||
where channel = 'monitoring_online' and processed is null
|
||||
order by stored asc
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_process_monitor_online_fn metadata_id [%]', process_rec.payload;
|
||||
SELECT * INTO metadata_rec
|
||||
FROM api.metadata
|
||||
WHERE id = process_rec.payload::INTEGER;
|
||||
|
||||
IF metadata_rec.vessel_id IS NULL OR metadata_rec.vessel_id = '' THEN
|
||||
RAISE WARNING '-> cron_process_monitor_online_fn invalid metadata record vessel_id %', vessel_id;
|
||||
RAISE EXCEPTION 'Invalid metadata'
|
||||
USING HINT = 'Unknown vessel_id';
|
||||
RETURN;
|
||||
END IF;
|
||||
PERFORM set_config('vessel.id', metadata_rec.vessel_id, false);
|
||||
RAISE DEBUG '-> DEBUG cron_process_monitor_online_fn vessel_id %', current_setting('vessel.id', false);
|
||||
|
||||
-- Gather email and pushover app settings
|
||||
--app_settings = get_app_settings_fn();
|
||||
-- Gather user settings
|
||||
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_vesselid_fn [%]', user_settings;
|
||||
-- Send notification
|
||||
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_pushover_py_fn('monitor_online'::TEXT, user_settings::JSONB, app_settings::JSONB);
|
||||
-- update process_queue entry as processed
|
||||
UPDATE process_queue
|
||||
SET
|
||||
processed = NOW()
|
||||
WHERE id = process_rec.id;
|
||||
RAISE NOTICE '-> cron_process_monitor_online_fn updated process_queue table [%]', process_rec.id;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_process_monitor_online_fn
|
||||
IS 'init by pg_cron to monitor back online pending notification, if so perform send_email or send_pushover base on user preferences';
|
||||
|
||||
-- CRON for new account pending notification
|
||||
CREATE FUNCTION cron_process_new_account_fn() RETURNS void AS $$
|
||||
declare
|
||||
process_rec record;
|
||||
begin
|
||||
-- Check for new account pending update
|
||||
RAISE NOTICE 'cron_process_new_account_fn';
|
||||
FOR process_rec in
|
||||
SELECT * from process_queue
|
||||
where channel = 'new_account' and processed is null
|
||||
order by stored asc
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_process_new_account_fn [%]', process_rec.payload;
|
||||
-- update account
|
||||
PERFORM process_account_queue_fn(process_rec.payload::TEXT);
|
||||
-- update process_queue entry as processed
|
||||
UPDATE process_queue
|
||||
SET
|
||||
processed = NOW()
|
||||
WHERE id = process_rec.id;
|
||||
RAISE NOTICE '-> cron_process_new_account_fn updated process_queue table [%]', process_rec.id;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_process_new_account_fn
|
||||
IS 'deprecated, init by pg_cron to check for new account pending update, if so perform process_account_queue_fn';
|
||||
|
||||
-- CRON for new account pending otp validation notification
|
||||
CREATE FUNCTION cron_process_new_account_otp_validation_fn() RETURNS void AS $$
|
||||
declare
|
||||
process_rec record;
|
||||
begin
|
||||
-- Check for new account pending update
|
||||
RAISE NOTICE 'cron_process_new_account_otp_validation_fn';
|
||||
FOR process_rec in
|
||||
SELECT * from process_queue
|
||||
where channel = 'new_account_otp' and processed is null
|
||||
order by stored asc
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_process_new_account_otp_validation_fn [%]', process_rec.payload;
|
||||
-- update account
|
||||
PERFORM process_account_otp_validation_queue_fn(process_rec.payload::TEXT);
|
||||
-- update process_queue entry as processed
|
||||
UPDATE process_queue
|
||||
SET
|
||||
processed = NOW()
|
||||
WHERE id = process_rec.id;
|
||||
RAISE NOTICE '-> cron_process_new_account_otp_validation_fn updated process_queue table [%]', process_rec.id;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_process_new_account_otp_validation_fn
|
||||
IS 'deprecated, init by pg_cron to check for new account otp pending update, if so perform process_account_otp_validation_queue_fn';
|
||||
|
||||
-- CRON for new vessel pending notification
|
||||
CREATE FUNCTION cron_process_new_vessel_fn() RETURNS void AS $$
|
||||
declare
|
||||
process_rec record;
|
||||
begin
|
||||
-- Check for new vessel pending update
|
||||
RAISE NOTICE 'cron_process_new_vessel_fn';
|
||||
FOR process_rec in
|
||||
SELECT * from process_queue
|
||||
where channel = 'new_vessel' and processed is null
|
||||
order by stored asc
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_process_new_vessel_fn [%]', process_rec.payload;
|
||||
-- update vessel
|
||||
PERFORM process_vessel_queue_fn(process_rec.payload::TEXT);
|
||||
-- update process_queue entry as processed
|
||||
UPDATE process_queue
|
||||
SET
|
||||
processed = NOW()
|
||||
WHERE id = process_rec.id;
|
||||
RAISE NOTICE '-> cron_process_new_vessel_fn updated process_queue table [%]', process_rec.id;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_process_new_vessel_fn
|
||||
IS 'deprecated, init by pg_cron to check for new vessel pending update, if so perform process_vessel_queue_fn';
|
||||
|
||||
-- CRON for new event notification
|
||||
CREATE FUNCTION cron_process_new_notification_fn() RETURNS void AS $$
|
||||
declare
|
||||
process_rec record;
|
||||
begin
|
||||
-- Check for new event notification pending update
|
||||
RAISE NOTICE 'cron_process_new_notification_fn';
|
||||
FOR process_rec in
|
||||
SELECT * FROM process_queue
|
||||
WHERE
|
||||
(channel = 'new_account' OR channel = 'new_vessel' OR channel = 'email_otp')
|
||||
and processed is null
|
||||
order by stored asc
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_process_new_notification_fn for [%]', process_rec.payload;
|
||||
-- process_notification_queue
|
||||
PERFORM process_notification_queue_fn(process_rec.payload::TEXT, process_rec.channel::TEXT);
|
||||
-- update process_queue entry as processed
|
||||
UPDATE process_queue
|
||||
SET
|
||||
processed = NOW()
|
||||
WHERE id = process_rec.id;
|
||||
RAISE NOTICE '-> cron_process_new_notification_fn updated process_queue table [%]', process_rec.id;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_process_new_notification_fn
|
||||
IS 'init by pg_cron to check for new event pending notifications, if so perform process_notification_queue_fn';
|
||||
|
||||
-- CRON for new vessel metadata pending grafana provisioning
|
||||
CREATE FUNCTION cron_process_grafana_fn() RETURNS void AS $$
|
||||
DECLARE
|
||||
process_rec record;
|
||||
data_rec record;
|
||||
app_settings jsonb;
|
||||
user_settings jsonb;
|
||||
BEGIN
|
||||
-- We run grafana provisioning only after the first received vessel metadata
|
||||
-- Check for new vessel metadata pending grafana provisioning
|
||||
RAISE NOTICE 'cron_process_grafana_fn';
|
||||
FOR process_rec in
|
||||
SELECT * from process_queue
|
||||
where channel = 'grafana' and processed is null
|
||||
order by stored asc
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_process_grafana_fn [%]', process_rec.payload;
|
||||
-- Gather url from app settings
|
||||
app_settings := get_app_settings_fn();
|
||||
-- Get vessel details base on metadata id
|
||||
SELECT * INTO data_rec
|
||||
FROM api.metadata m, auth.vessels v
|
||||
WHERE m.id = process_rec.payload::INTEGER
|
||||
AND m.vessel_id = v.vessel_id;
|
||||
-- as we got data from the vessel we can do the grafana provisioning.
|
||||
PERFORM grafana_py_fn(data_rec.name, data_rec.vessel_id, data_rec.owner_email, app_settings);
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(data_rec.vessel_id::TEXT);
|
||||
--RAISE DEBUG '-> DEBUG cron_process_grafana_fn get_user_settings_from_vesselid_fn [%]', user_settings;
|
||||
-- add user in keycloak
|
||||
PERFORM keycloak_auth_py_fn(data_rec.vessel_id, user_settings, app_settings);
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('grafana'::TEXT, user_settings::JSONB);
|
||||
-- update process_queue entry as processed
|
||||
UPDATE process_queue
|
||||
SET
|
||||
processed = NOW()
|
||||
WHERE id = process_rec.id;
|
||||
RAISE NOTICE '-> cron_process_grafana_fn updated process_queue table [%]', process_rec.id;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_process_grafana_fn
|
||||
IS 'init by pg_cron to check for new vessel pending grafana provisioning, if so perform grafana_py_fn';
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.cron_process_windy_fn() RETURNS void AS $$
|
||||
DECLARE
|
||||
windy_rec record;
|
||||
default_last_metric TIMESTAMPTZ := NOW() - interval '1 day';
|
||||
last_metric TIMESTAMPTZ;
|
||||
metric_rec record;
|
||||
windy_metric jsonb;
|
||||
app_settings jsonb;
|
||||
user_settings jsonb;
|
||||
windy_pws jsonb;
|
||||
BEGIN
|
||||
-- Check for new observations pending update
|
||||
RAISE NOTICE 'cron_windy_fn';
|
||||
-- Gather url from app settings
|
||||
app_settings := get_app_settings_fn();
|
||||
-- Find users with Windy active and with an active vessel
|
||||
-- Map account id to Windy Station ID
|
||||
FOR windy_rec in
|
||||
SELECT
|
||||
a.id,a.email,v.vessel_id,v.name,
|
||||
COALESCE((a.preferences->'windy_last_metric')::TEXT, default_last_metric::TEXT) as last_metric
|
||||
FROM auth.accounts a
|
||||
LEFT JOIN auth.vessels AS v ON v.owner_email = a.email
|
||||
LEFT JOIN api.metadata AS m ON m.vessel_id = v.vessel_id
|
||||
WHERE (a.preferences->'public_windy')::boolean = True
|
||||
AND m.active = True
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_windy_fn for [%]', windy_rec;
|
||||
PERFORM set_config('vessel.id', windy_rec.vessel_id, false);
|
||||
--RAISE WARNING 'public.cron_process_windy_rec_fn() scheduler vessel.id %, user.id', current_setting('vessel.id', false), current_setting('user.id', false);
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(windy_rec.vessel_id::TEXT);
|
||||
RAISE NOTICE '-> cron_windy_fn checking user_settings [%]', user_settings;
|
||||
-- Get all metrics from the last windy_last_metric avg by 5 minutes
|
||||
-- TODO json_agg to send all data in once, but issue with py jsonb transformation decimal.
|
||||
FOR metric_rec in
|
||||
SELECT time_bucket('5 minutes', m.time) AS time_bucket,
|
||||
avg((m.metrics->'environment.outside.temperature')::numeric) AS temperature,
|
||||
avg((m.metrics->'environment.outside.pressure')::numeric) AS pressure,
|
||||
avg((m.metrics->'environment.outside.relativeHumidity')::numeric) AS rh,
|
||||
avg((m.metrics->'environment.wind.directionTrue')::numeric) AS winddir,
|
||||
avg((m.metrics->'environment.wind.speedTrue')::numeric) AS wind,
|
||||
max((m.metrics->'environment.wind.speedTrue')::numeric) AS gust,
|
||||
last(latitude, time) AS lat,
|
||||
last(longitude, time) AS lng
|
||||
FROM api.metrics m
|
||||
WHERE vessel_id = windy_rec.vessel_id
|
||||
AND m.time >= windy_rec.last_metric::TIMESTAMPTZ
|
||||
GROUP BY time_bucket
|
||||
ORDER BY time_bucket ASC LIMIT 100
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_windy_fn checking metrics [%]', metric_rec;
|
||||
-- https://community.windy.com/topic/8168/report-your-weather-station-data-to-windy
|
||||
-- temp from kelvin to celcuis
|
||||
-- winddir from radiant to degres
|
||||
-- rh from ratio to percentage
|
||||
SELECT jsonb_build_object(
|
||||
'dateutc', metric_rec.time_bucket,
|
||||
'station', windy_rec.id,
|
||||
'name', windy_rec.name,
|
||||
'lat', metric_rec.lat,
|
||||
'lon', metric_rec.lng,
|
||||
'wind', metric_rec.wind,
|
||||
'gust', metric_rec.gust,
|
||||
'pressure', metric_rec.pressure,
|
||||
'winddir', radiantToDegrees(metric_rec.winddir::numeric),
|
||||
'temp', kelvinToCel(metric_rec.temperature::numeric),
|
||||
'rh', valToPercent(metric_rec.rh::numeric)
|
||||
) INTO windy_metric;
|
||||
RAISE NOTICE '-> cron_windy_fn checking windy_metrics [%]', windy_metric;
|
||||
SELECT windy_pws_py_fn(windy_metric, user_settings, app_settings) into windy_pws;
|
||||
RAISE NOTICE '-> cron_windy_fn Windy PWS [%]', ((windy_pws->'header')::JSONB ? 'id');
|
||||
IF NOT((user_settings->'settings')::JSONB ? 'windy') and ((windy_pws->'header')::JSONB ? 'id') then
|
||||
RAISE NOTICE '-> cron_windy_fn new Windy PWS [%]', (windy_pws->'header')::JSONB->>'id';
|
||||
-- Send metrics to Windy
|
||||
PERFORM api.update_user_preferences_fn('{windy}'::TEXT, ((windy_pws->'header')::JSONB->>'id')::TEXT);
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('windy'::TEXT, user_settings::JSONB);
|
||||
END IF;
|
||||
-- Record last metrics time
|
||||
SELECT metric_rec.time_bucket INTO last_metric;
|
||||
END LOOP;
|
||||
PERFORM api.update_user_preferences_fn('{windy_last_metric}'::TEXT, last_metric::TEXT);
|
||||
END LOOP;
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_process_windy_fn
|
||||
IS 'init by pg_cron to create (or update) station and uploading observations to Windy Personal Weather Station observations';
|
||||
|
||||
-- CRON for Vacuum database
|
||||
CREATE FUNCTION cron_vacuum_fn() RETURNS void AS $$
|
||||
-- ERROR: VACUUM cannot be executed from a function
|
||||
declare
|
||||
begin
|
||||
-- Vacuum
|
||||
RAISE NOTICE 'cron_vacuum_fn';
|
||||
VACUUM (FULL, VERBOSE, ANALYZE, INDEX_CLEANUP) api.logbook;
|
||||
VACUUM (FULL, VERBOSE, ANALYZE, INDEX_CLEANUP) api.stays;
|
||||
VACUUM (FULL, VERBOSE, ANALYZE, INDEX_CLEANUP) api.moorages;
|
||||
VACUUM (FULL, VERBOSE, ANALYZE, INDEX_CLEANUP) api.metrics;
|
||||
VACUUM (FULL, VERBOSE, ANALYZE, INDEX_CLEANUP) api.metadata;
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_vacuum_fn
|
||||
IS 'init by pg_cron to full vacuum tables on schema api';
|
||||
|
||||
-- CRON for alerts notification
|
||||
CREATE OR REPLACE FUNCTION public.cron_alerts_fn() RETURNS void AS $$
|
||||
DECLARE
|
||||
alert_rec record;
|
||||
default_last_metric TIMESTAMPTZ := NOW() - interval '1 day';
|
||||
last_metric TIMESTAMPTZ;
|
||||
metric_rec record;
|
||||
app_settings JSONB;
|
||||
user_settings JSONB;
|
||||
alerting JSONB;
|
||||
_alarms JSONB;
|
||||
alarms TEXT;
|
||||
alert_default JSONB := '{
|
||||
"low_pressure_threshold": 990,
|
||||
"high_wind_speed_threshold": 30,
|
||||
"low_water_depth_threshold": 1,
|
||||
"min_notification_interval": 6,
|
||||
"high_pressure_drop_threshold": 12,
|
||||
"low_battery_charge_threshold": 90,
|
||||
"low_battery_voltage_threshold": 12.5,
|
||||
"low_water_temperature_threshold": 10,
|
||||
"low_indoor_temperature_threshold": 7,
|
||||
"low_outdoor_temperature_threshold": 3
|
||||
}';
|
||||
BEGIN
|
||||
-- Check for new event notification pending update
|
||||
RAISE NOTICE 'cron_alerts_fn';
|
||||
FOR alert_rec in
|
||||
SELECT
|
||||
a.user_id,a.email,v.vessel_id,
|
||||
COALESCE((a.preferences->'alert_last_metric')::TEXT, default_last_metric::TEXT) as last_metric,
|
||||
(alert_default || (a.preferences->'alerting')::JSONB) as alerting,
|
||||
(a.preferences->'alarms')::JSONB as alarms
|
||||
FROM auth.accounts a
|
||||
LEFT JOIN auth.vessels AS v ON v.owner_email = a.email
|
||||
LEFT JOIN api.metadata AS m ON m.vessel_id = v.vessel_id
|
||||
WHERE (a.preferences->'alerting'->'enabled')::boolean = True
|
||||
AND m.active = True
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_alerts_fn for [%]', alert_rec;
|
||||
PERFORM set_config('vessel.id', alert_rec.vessel_id, false);
|
||||
PERFORM set_config('user.email', alert_rec.email, false);
|
||||
--RAISE WARNING 'public.cron_process_alert_rec_fn() scheduler vessel.id %, user.id', current_setting('vessel.id', false), current_setting('user.id', false);
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(alert_rec.vessel_id::TEXT);
|
||||
RAISE NOTICE '-> cron_alerts_fn checking user_settings [%]', user_settings;
|
||||
-- Get all metrics from the last last_metric avg by 5 minutes
|
||||
FOR metric_rec in
|
||||
SELECT time_bucket('5 minutes', m.time) AS time_bucket,
|
||||
avg((m.metrics->'environment.inside.temperature')::numeric) AS intemp,
|
||||
avg((m.metrics->'environment.outside.temperature')::numeric) AS outtemp,
|
||||
avg((m.metrics->'environment.water.temperature')::numeric) AS wattemp,
|
||||
avg((m.metrics->'environment.depth.belowTransducer')::numeric) AS watdepth,
|
||||
avg((m.metrics->'environment.outside.pressure')::numeric) AS pressure,
|
||||
avg((m.metrics->'environment.wind.speedTrue')::numeric) AS wind,
|
||||
avg((m.metrics->'electrical.batteries.House.voltage')::numeric) AS voltage,
|
||||
avg((m.metrics->'electrical.batteries.House.capacity.stateOfCharge')::numeric) AS charge
|
||||
FROM api.metrics m
|
||||
WHERE vessel_id = alert_rec.vessel_id
|
||||
AND m.time >= alert_rec.last_metric::TIMESTAMPTZ
|
||||
GROUP BY time_bucket
|
||||
ORDER BY time_bucket ASC LIMIT 100
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_alerts_fn checking metrics [%]', metric_rec;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking alerting [%]', alert_rec.alerting;
|
||||
--RAISE NOTICE '-> cron_alerts_fn checking debug [%] [%]', kelvinToCel(metric_rec.intemp), (alert_rec.alerting->'low_indoor_temperature_threshold');
|
||||
IF kelvinToCel(metric_rec.intemp) < (alert_rec.alerting->'low_indoor_temperature_threshold')::numeric then
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_indoor_temperature_threshold'->>'date')::TIMESTAMPTZ;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', metric_rec.time_bucket::TIMESTAMPTZ;
|
||||
-- Get latest alarms
|
||||
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
|
||||
-- Is alarm in the min_notification_interval time frame
|
||||
IF (
|
||||
((_alarms->'low_indoor_temperature_threshold'->>'date') IS NULL) OR
|
||||
(((_alarms->'low_indoor_temperature_threshold'->>'date')::TIMESTAMPTZ
|
||||
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
|
||||
< metric_rec.time_bucket::TIMESTAMPTZ)
|
||||
) THEN
|
||||
-- Add alarm
|
||||
alarms := '{"low_indoor_temperature_threshold": {"value": '|| kelvinToCel(metric_rec.intemp) ||', "date":"' || metric_rec.time_bucket || '"}}';
|
||||
-- Merge alarms
|
||||
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
|
||||
-- Update alarms for user
|
||||
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
|
||||
SELECT user_settings::JSONB || ('{"alert": "low_outdoor_temperature_threshold value:'|| kelvinToCel(metric_rec.intemp) ||'"}'::text)::JSONB into user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
|
||||
-- DEBUG
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_indoor_temperature_threshold +interval';
|
||||
END IF;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_indoor_temperature_threshold';
|
||||
END IF;
|
||||
IF kelvinToCel(metric_rec.outtemp) < (alert_rec.alerting->'low_outdoor_temperature_threshold')::numeric then
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_outdoor_temperature_threshold'->>'date')::TIMESTAMPTZ;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', metric_rec.time_bucket::TIMESTAMPTZ;
|
||||
-- Get latest alarms
|
||||
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
|
||||
-- Is alarm in the min_notification_interval time frame
|
||||
IF (
|
||||
((_alarms->'low_outdoor_temperature_threshold'->>'date') IS NULL) OR
|
||||
(((_alarms->'low_outdoor_temperature_threshold'->>'date')::TIMESTAMPTZ
|
||||
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
|
||||
< metric_rec.time_bucket::TIMESTAMPTZ)
|
||||
) THEN
|
||||
-- Add alarm
|
||||
alarms := '{"low_outdoor_temperature_threshold": {"value": '|| kelvinToCel(metric_rec.outtemp) ||', "date":"' || metric_rec.time_bucket || '"}}';
|
||||
-- Merge alarms
|
||||
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
|
||||
-- Update alarms for user
|
||||
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
|
||||
SELECT user_settings::JSONB || ('{"alert": "low_outdoor_temperature_threshold value:'|| kelvinToCel(metric_rec.outtemp) ||'"}'::text)::JSONB into user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
|
||||
-- DEBUG
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_outdoor_temperature_threshold +interval';
|
||||
END IF;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_outdoor_temperature_threshold';
|
||||
END IF;
|
||||
IF kelvinToCel(metric_rec.wattemp) < (alert_rec.alerting->'low_water_temperature_threshold')::numeric then
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_water_temperature_threshold'->>'date')::TIMESTAMPTZ;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', metric_rec.time_bucket::TIMESTAMPTZ;
|
||||
-- Get latest alarms
|
||||
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
|
||||
-- Is alarm in the min_notification_interval time frame
|
||||
IF (
|
||||
((_alarms->'low_water_temperature_threshold'->>'date') IS NULL) OR
|
||||
(((_alarms->'low_water_temperature_threshold'->>'date')::TIMESTAMPTZ
|
||||
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
|
||||
< metric_rec.time_bucket::TIMESTAMPTZ)
|
||||
) THEN
|
||||
-- Add alarm
|
||||
alarms := '{"low_water_temperature_threshold": {"value": '|| kelvinToCel(metric_rec.wattemp) ||', "date":"' || metric_rec.time_bucket || '"}}';
|
||||
-- Merge alarms
|
||||
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
|
||||
-- Update alarms for user
|
||||
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
|
||||
SELECT user_settings::JSONB || ('{"alert": "low_water_temperature_threshold value:'|| kelvinToCel(metric_rec.wattemp) ||'"}'::text)::JSONB into user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
|
||||
-- DEBUG
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_water_temperature_threshold +interval';
|
||||
END IF;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_water_temperature_threshold';
|
||||
END IF;
|
||||
IF metric_rec.watdepth < (alert_rec.alerting->'low_water_depth_threshold')::numeric then
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_water_depth_threshold'->>'date')::TIMESTAMPTZ;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', metric_rec.time_bucket::TIMESTAMPTZ;
|
||||
-- Get latest alarms
|
||||
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
|
||||
-- Is alarm in the min_notification_interval time frame
|
||||
IF (
|
||||
((_alarms->'low_water_depth_threshold'->>'date') IS NULL) OR
|
||||
(((_alarms->'low_water_depth_threshold'->>'date')::TIMESTAMPTZ
|
||||
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
|
||||
< metric_rec.time_bucket::TIMESTAMPTZ)
|
||||
) THEN
|
||||
-- Add alarm
|
||||
alarms := '{"low_water_depth_threshold": {"value": '|| metric_rec.watdepth ||', "date":"' || metric_rec.time_bucket || '"}}';
|
||||
-- Merge alarms
|
||||
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
|
||||
-- Update alarms for user
|
||||
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
|
||||
SELECT user_settings::JSONB || ('{"alert": "low_water_depth_threshold value:'|| metric_rec.watdepth ||'"}'::text)::JSONB into user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
|
||||
-- DEBUG
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_water_depth_threshold +interval';
|
||||
END IF;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_water_depth_threshold';
|
||||
END IF;
|
||||
if metric_rec.pressure < (alert_rec.alerting->'high_pressure_drop_threshold')::numeric then
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'high_pressure_drop_threshold'->>'date')::TIMESTAMPTZ;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', metric_rec.time_bucket::TIMESTAMPTZ;
|
||||
-- Get latest alarms
|
||||
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
|
||||
-- Is alarm in the min_notification_interval time frame
|
||||
IF (
|
||||
((_alarms->'high_pressure_drop_threshold'->>'date') IS NULL) OR
|
||||
(((_alarms->'high_pressure_drop_threshold'->>'date')::TIMESTAMPTZ
|
||||
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
|
||||
< metric_rec.time_bucket::TIMESTAMPTZ)
|
||||
) THEN
|
||||
-- Add alarm
|
||||
alarms := '{"high_pressure_drop_threshold": {"value": '|| metric_rec.pressure ||', "date":"' || metric_rec.time_bucket || '"}}';
|
||||
-- Merge alarms
|
||||
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
|
||||
-- Update alarms for user
|
||||
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
|
||||
SELECT user_settings::JSONB || ('{"alert": "high_pressure_drop_threshold value:'|| metric_rec.pressure ||'"}'::text)::JSONB into user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
|
||||
-- DEBUG
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug high_pressure_drop_threshold +interval';
|
||||
END IF;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug high_pressure_drop_threshold';
|
||||
END IF;
|
||||
IF metric_rec.wind > (alert_rec.alerting->'high_wind_speed_threshold')::numeric then
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'high_wind_speed_threshold'->>'date')::TIMESTAMPTZ;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', metric_rec.time_bucket::TIMESTAMPTZ;
|
||||
-- Get latest alarms
|
||||
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
|
||||
-- Is alarm in the min_notification_interval time frame
|
||||
IF (
|
||||
((_alarms->'high_wind_speed_threshold'->>'date') IS NULL) OR
|
||||
(((_alarms->'high_wind_speed_threshold'->>'date')::TIMESTAMPTZ
|
||||
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
|
||||
< metric_rec.time_bucket::TIMESTAMPTZ)
|
||||
) THEN
|
||||
-- Add alarm
|
||||
alarms := '{"high_wind_speed_threshold": {"value": '|| metric_rec.wind ||', "date":"' || metric_rec.time_bucket || '"}}';
|
||||
-- Merge alarms
|
||||
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
|
||||
-- Update alarms for user
|
||||
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
|
||||
SELECT user_settings::JSONB || ('{"alert": "high_wind_speed_threshold value:'|| metric_rec.wind ||'"}'::text)::JSONB into user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
|
||||
-- DEBUG
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug high_wind_speed_threshold +interval';
|
||||
END IF;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug high_wind_speed_threshold';
|
||||
END IF;
|
||||
if metric_rec.voltage < (alert_rec.alerting->'low_battery_voltage_threshold')::numeric then
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_battery_voltage_threshold'->>'date')::TIMESTAMPTZ;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', metric_rec.time_bucket::TIMESTAMPTZ;
|
||||
-- Get latest alarms
|
||||
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = 'lacroix.francois@gmail.com';
|
||||
-- Is alarm in the min_notification_interval time frame
|
||||
IF (
|
||||
((_alarms->'low_battery_voltage_threshold'->>'date') IS NULL) OR
|
||||
(((_alarms->'low_battery_voltage_threshold'->>'date')::TIMESTAMPTZ
|
||||
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
|
||||
< metric_rec.time_bucket::TIMESTAMPTZ)
|
||||
) THEN
|
||||
-- Add alarm
|
||||
alarms := '{"low_battery_voltage_threshold": {"value": '|| metric_rec.voltage ||', "date":"' || metric_rec.time_bucket || '"}}';
|
||||
-- Merge alarms
|
||||
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
|
||||
-- Update alarms for user
|
||||
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
|
||||
SELECT user_settings::JSONB || ('{"alert": "low_battery_voltage_threshold value:'|| metric_rec.voltage ||'"}'::text)::JSONB into user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
|
||||
-- DEBUG
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_battery_voltage_threshold +interval';
|
||||
END IF;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_battery_voltage_threshold';
|
||||
END IF;
|
||||
if (metric_rec.charge*100) < (alert_rec.alerting->'low_battery_charge_threshold')::numeric then
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_battery_charge_threshold'->>'date')::TIMESTAMPTZ;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', metric_rec.time_bucket::TIMESTAMPTZ;
|
||||
-- Get latest alarms
|
||||
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
|
||||
-- Is alarm in the min_notification_interval time frame
|
||||
IF (
|
||||
((_alarms->'low_battery_charge_threshold'->>'date') IS NULL) OR
|
||||
(((_alarms->'low_battery_charge_threshold'->>'date')::TIMESTAMPTZ
|
||||
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
|
||||
< metric_rec.time_bucket::TIMESTAMPTZ)
|
||||
) THEN
|
||||
-- Add alarm
|
||||
alarms := '{"low_battery_charge_threshold": {"value": '|| (metric_rec.charge*100) ||', "date":"' || metric_rec.time_bucket || '"}}';
|
||||
-- Merge alarms
|
||||
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
|
||||
-- Update alarms for user
|
||||
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
|
||||
SELECT user_settings::JSONB || ('{"alert": "low_battery_charge_threshold value:'|| (metric_rec.charge*100) ||'"}'::text)::JSONB into user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
|
||||
-- DEBUG
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_battery_charge_threshold +interval';
|
||||
END IF;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_battery_charge_threshold';
|
||||
END IF;
|
||||
-- Record last metrics time
|
||||
SELECT metric_rec.time_bucket INTO last_metric;
|
||||
END LOOP;
|
||||
PERFORM api.update_user_preferences_fn('{alert_last_metric}'::TEXT, last_metric::TEXT);
|
||||
END LOOP;
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_alerts_fn
|
||||
IS 'init by pg_cron to check for alerts';
|
||||
|
||||
-- CRON for no vessel notification
|
||||
CREATE FUNCTION cron_process_no_vessel_fn() RETURNS void AS $no_vessel$
|
||||
DECLARE
|
||||
no_vessel record;
|
||||
user_settings jsonb;
|
||||
BEGIN
|
||||
-- Check for user with no vessel register
|
||||
RAISE NOTICE 'cron_process_no_vessel_fn';
|
||||
FOR no_vessel in
|
||||
SELECT a.user_id,a.email,a.first
|
||||
FROM auth.accounts a
|
||||
WHERE NOT EXISTS (
|
||||
SELECT *
|
||||
FROM auth.vessels v
|
||||
WHERE v.owner_email = a.email)
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_process_no_vessel_rec_fn for [%]', no_vessel;
|
||||
SELECT json_build_object('email', no_vessel.email, 'recipient', no_vessel.first) into user_settings;
|
||||
RAISE NOTICE '-> debug cron_process_no_vessel_rec_fn [%]', user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('no_vessel'::TEXT, user_settings::JSONB);
|
||||
END LOOP;
|
||||
END;
|
||||
$no_vessel$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_process_no_vessel_fn
|
||||
IS 'init by pg_cron, check for user with no vessel register then send notification';
|
||||
|
||||
-- CRON for no metadata notification
|
||||
CREATE FUNCTION cron_process_no_metadata_fn() RETURNS void AS $no_metadata$
|
||||
DECLARE
|
||||
no_metadata_rec record;
|
||||
user_settings jsonb;
|
||||
BEGIN
|
||||
-- Check for vessel register but with no metadata
|
||||
RAISE NOTICE 'cron_process_no_metadata_fn';
|
||||
FOR no_metadata_rec in
|
||||
SELECT
|
||||
a.user_id,a.email,a.first
|
||||
FROM auth.accounts a, auth.vessels v
|
||||
WHERE NOT EXISTS (
|
||||
SELECT *
|
||||
FROM api.metadata m
|
||||
WHERE v.vessel_id = m.vessel_id) AND v.owner_email = a.email
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_process_no_metadata_rec_fn for [%]', no_metadata_rec;
|
||||
SELECT json_build_object('email', no_metadata_rec.email, 'recipient', no_metadata_rec.first) into user_settings;
|
||||
RAISE NOTICE '-> debug cron_process_no_metadata_rec_fn [%]', user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('no_metadata'::TEXT, user_settings::JSONB);
|
||||
END LOOP;
|
||||
END;
|
||||
$no_metadata$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_process_no_metadata_fn
|
||||
IS 'init by pg_cron, check for vessel with no metadata then send notification';
|
||||
|
||||
-- CRON for no activity notification
|
||||
CREATE FUNCTION cron_process_no_activity_fn() RETURNS void AS $no_activity$
|
||||
DECLARE
|
||||
no_activity_rec record;
|
||||
user_settings jsonb;
|
||||
BEGIN
|
||||
-- Check for vessel with no activity for more than 230 days
|
||||
RAISE NOTICE 'cron_process_no_activity_fn';
|
||||
FOR no_activity_rec in
|
||||
SELECT
|
||||
v.owner_email,m.name,m.vessel_id,m.time,a.first
|
||||
FROM auth.accounts a
|
||||
LEFT JOIN auth.vessels v ON v.owner_email = a.email
|
||||
LEFT JOIN api.metadata m ON v.vessel_id = m.vessel_id
|
||||
WHERE m.time < NOW() AT TIME ZONE 'UTC' - INTERVAL '230 DAYS'
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_process_no_activity_rec_fn for [%]', no_activity_rec;
|
||||
SELECT json_build_object('email', no_activity_rec.owner_email, 'recipient', no_activity_rec.first) into user_settings;
|
||||
RAISE NOTICE '-> debug cron_process_no_activity_rec_fn [%]', user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('no_activity'::TEXT, user_settings::JSONB);
|
||||
END LOOP;
|
||||
END;
|
||||
$no_activity$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_process_no_activity_fn
|
||||
IS 'init by pg_cron, check for vessel with no activity for more than 230 days then send notification';
|
||||
|
||||
-- CRON for deactivated/deletion
|
||||
CREATE FUNCTION cron_process_deactivated_fn() RETURNS void AS $deactivated$
|
||||
DECLARE
|
||||
no_activity_rec record;
|
||||
user_settings jsonb;
|
||||
BEGIN
|
||||
RAISE NOTICE 'cron_process_deactivated_fn';
|
||||
|
||||
-- List accounts with vessel inactivity for more than 1 YEAR
|
||||
FOR no_activity_rec in
|
||||
SELECT
|
||||
v.owner_email,m.name,m.vessel_id,m.time,a.first
|
||||
FROM auth.accounts a
|
||||
LEFT JOIN auth.vessels v ON v.owner_email = a.email
|
||||
LEFT JOIN api.metadata m ON v.vessel_id = m.vessel_id
|
||||
WHERE m.time < NOW() AT TIME ZONE 'UTC' - INTERVAL '1 YEAR'
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_process_deactivated_rec_fn for inactivity [%]', no_activity_rec;
|
||||
SELECT json_build_object('email', no_activity_rec.owner_email, 'recipient', no_activity_rec.first) into user_settings;
|
||||
RAISE NOTICE '-> debug cron_process_deactivated_rec_fn inactivity [%]', user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('deactivated'::TEXT, user_settings::JSONB);
|
||||
--PERFORM public.delete_account_fn(no_activity_rec.owner_email::TEXT, no_activity_rec.vessel_id::TEXT);
|
||||
END LOOP;
|
||||
|
||||
-- List accounts with no vessel metadata for more than 1 YEAR
|
||||
FOR no_activity_rec in
|
||||
SELECT
|
||||
a.user_id,a.email,a.first,a.created_at
|
||||
FROM auth.accounts a, auth.vessels v
|
||||
WHERE NOT EXISTS (
|
||||
SELECT *
|
||||
FROM api.metadata m
|
||||
WHERE v.vessel_id = m.vessel_id) AND v.owner_email = a.email
|
||||
AND v.created_at < NOW() AT TIME ZONE 'UTC' - INTERVAL '1 YEAR'
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_process_deactivated_rec_fn for no metadata [%]', no_activity_rec;
|
||||
SELECT json_build_object('email', no_activity_rec.owner_email, 'recipient', no_activity_rec.first) into user_settings;
|
||||
RAISE NOTICE '-> debug cron_process_deactivated_rec_fn no metadata [%]', user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('deactivated'::TEXT, user_settings::JSONB);
|
||||
--PERFORM public.delete_account_fn(no_activity_rec.owner_email::TEXT, no_activity_rec.vessel_id::TEXT);
|
||||
END LOOP;
|
||||
|
||||
-- List accounts with no vessel created for more than 1 YEAR
|
||||
FOR no_activity_rec in
|
||||
SELECT a.user_id,a.email,a.first,a.created_at
|
||||
FROM auth.accounts a
|
||||
WHERE NOT EXISTS (
|
||||
SELECT *
|
||||
FROM auth.vessels v
|
||||
WHERE v.owner_email = a.email)
|
||||
AND a.created_at < NOW() AT TIME ZONE 'UTC' - INTERVAL '1 YEAR'
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_process_deactivated_rec_fn for no vessel [%]', no_activity_rec;
|
||||
SELECT json_build_object('email', no_activity_rec.owner_email, 'recipient', no_activity_rec.first) into user_settings;
|
||||
RAISE NOTICE '-> debug cron_process_deactivated_rec_fn no vessel [%]', user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('deactivated'::TEXT, user_settings::JSONB);
|
||||
--PERFORM public.delete_account_fn(no_activity_rec.owner_email::TEXT, no_activity_rec.vessel_id::TEXT);
|
||||
END LOOP;
|
||||
END;
|
||||
$deactivated$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_process_deactivated_fn
|
||||
IS 'init by pg_cron, check for vessel with no activity for more than 1 year then send notification and delete data';
|
||||
|
||||
-- Need to be in the postgres database.
|
||||
\c postgres
|
||||
-- CRON for clean up job details logs
|
||||
CREATE FUNCTION public.job_run_details_cleanup_fn() RETURNS void AS $$
|
||||
DECLARE
|
||||
BEGIN
|
||||
-- Remove job run log older than 3 months
|
||||
RAISE NOTICE 'job_run_details_cleanup_fn';
|
||||
DELETE FROM cron.job_run_details
|
||||
WHERE start_time <= NOW() AT TIME ZONE 'UTC' - INTERVAL '91 DAYS';
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.job_run_details_cleanup_fn
|
||||
IS 'init by pg_cron to cleanup job_run_details table on schema public postgres db';
|
937
initdb/02_3_1_signalk_public_tables.sql
Normal file
937
initdb/02_3_1_signalk_public_tables.sql
Normal file
@@ -0,0 +1,937 @@
|
||||
---------------------------------------------------------------------------
|
||||
-- singalk db public schema tables
|
||||
--
|
||||
|
||||
-- List current database
|
||||
select current_database();
|
||||
|
||||
-- connect to the DB
|
||||
\c signalk
|
||||
|
||||
CREATE SCHEMA IF NOT EXISTS public;
|
||||
COMMENT ON SCHEMA public IS 'backend public functions and tables';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Table geocoders
|
||||
--
|
||||
-- https://github.com/CartoDB/labs-postgresql/blob/master/workshop/plpython.md
|
||||
--
|
||||
CREATE TABLE IF NOT EXISTS geocoders(
|
||||
name TEXT UNIQUE,
|
||||
url TEXT,
|
||||
reverse_url TEXT
|
||||
);
|
||||
-- Description
|
||||
COMMENT ON TABLE
|
||||
public.geocoders
|
||||
IS 'geo service nominatim url';
|
||||
|
||||
INSERT INTO geocoders VALUES
|
||||
('nominatim',
|
||||
NULL,
|
||||
'https://nominatim.openstreetmap.org/reverse');
|
||||
-- https://photon.komoot.io/reverse?lat=48.30587233333333&lon=14.3040525
|
||||
-- https://docs.mapbox.com/playground/geocoding/?search_text=-3.1457869856990897,51.35921326434686&limit=1
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Tables for message template email/pushover/telegram
|
||||
--
|
||||
DROP TABLE IF EXISTS public.email_templates;
|
||||
CREATE TABLE IF NOT EXISTS public.email_templates(
|
||||
name TEXT UNIQUE,
|
||||
email_subject TEXT,
|
||||
email_content TEXT,
|
||||
pushover_title TEXT,
|
||||
pushover_message TEXT
|
||||
);
|
||||
-- Description
|
||||
COMMENT ON TABLE
|
||||
public.email_templates
|
||||
IS 'email/message templates for notifications';
|
||||
|
||||
-- with escape value, eg: E'A\nB\r\nC'
|
||||
-- https://stackoverflow.com/questions/26638615/insert-line-break-in-postgresql-when-updating-text-field
|
||||
-- TODO Update notification subject for log entry to 'logbook #NB ...'
|
||||
INSERT INTO public.email_templates VALUES
|
||||
('logbook',
|
||||
'New Logbook Entry',
|
||||
E'Hello __RECIPIENT__,\n\nWe just wanted to let you know that you have a new entry on openplotter.cloud: "__LOGBOOK_NAME__"\r\n\r\nSee more details at __APP_URL__/log/__LOGBOOK_LINK__\n\nHappy sailing!\nThe PostgSail Team',
|
||||
'New Logbook Entry',
|
||||
E'New entry on openplotter.cloud: "__LOGBOOK_NAME__"\r\nSee more details at __APP_URL__/log/__LOGBOOK_LINK__\n'),
|
||||
('new_account',
|
||||
'Welcome',
|
||||
E'Hello __RECIPIENT__,\nCongratulations!\nYou successfully created an account.\nKeep in mind to register your vessel.\nHappy sailing!',
|
||||
'Welcome',
|
||||
E'Hi!\nYou successfully created an account\nKeep in mind to register your vessel.\n'),
|
||||
('new_vessel',
|
||||
'New boat',
|
||||
E'Hi!\nHow are you?\n__BOAT__ is now linked to your account.\n',
|
||||
'New boat',
|
||||
E'Hi!\nHow are you?\n__BOAT__ is now linked to your account.\n'),
|
||||
('monitor_offline',
|
||||
'Boat went Offline',
|
||||
E'__BOAT__ has been offline for more than an hour\r\nFind more details at __APP_URL__/boats\n',
|
||||
'Boat went Offline',
|
||||
E'__BOAT__ has been offline for more than an hour\r\nFind more details at __APP_URL__/boats\n'),
|
||||
('monitor_online',
|
||||
'Boat went Online',
|
||||
E'__BOAT__ just came online\nFind more details at __APP_URL__/boats\n',
|
||||
'Boat went Online',
|
||||
E'__BOAT__ just came online\nFind more details at __APP_URL__/boats\n'),
|
||||
('new_badge',
|
||||
'New Badge!',
|
||||
E'Hello __RECIPIENT__,\nCongratulations! You have just unlocked a new badge: __BADGE_NAME__\nSee more details at __APP_URL__/badges\nHappy sailing!\nThe PostgSail Team',
|
||||
'New Badge!',
|
||||
E'Congratulations!\nYou have just unlocked a new badge: __BADGE_NAME__\nSee more details at __APP_URL__/badges\n'),
|
||||
('pushover_valid',
|
||||
'Pushover integration',
|
||||
E'Hello __RECIPIENT__,\nCongratulations! You have just connect your account to Pushover.\n\nThe PostgSail Team',
|
||||
'Pushover integration!',
|
||||
E'Congratulations!\nYou have just connect your account to Pushover.\n'),
|
||||
('email_otp',
|
||||
'Email verification',
|
||||
E'Hello,\nPlease active your account using the following code: __OTP_CODE__.\nThe code is valid 15 minutes.\nThe PostgSail Team',
|
||||
'Email verification',
|
||||
E'Congratulations!\nPlease validate your account. Check your email!'),
|
||||
('email_valid',
|
||||
'Email verified',
|
||||
E'Hello,\nCongratulations!\nYou successfully validate your account.\nThe PostgSail Team',
|
||||
'Email verified',
|
||||
E'Hi!\nYou successfully validate your account.\n'),
|
||||
('email_reset',
|
||||
'Password reset',
|
||||
E'Hello,\nYou requested a password reset. To reset your password __APP_URL__/reset-password?__RESET_QS__.\nThe PostgSail Team',
|
||||
'Password reset',
|
||||
E'You requested a password recovery. Check your email!\n'),
|
||||
('telegram_otp',
|
||||
'Telegram bot',
|
||||
E'Hello,\nTo connect your account to a @postgsail_bot. Please type this verification code __OTP_CODE__ back to the bot.\nThe code is valid 15 minutes.\nFrancois',
|
||||
'Telegram bot',
|
||||
E'Hello,\nTo connect your account to a @postgsail_bot. Check your email!\n'),
|
||||
('telegram_valid',
|
||||
'Telegram bot',
|
||||
E'Hello __RECIPIENT__,\nCongratulations! You have just connect your account to your vessel, @postgsail_bot.\nFrancois',
|
||||
'Telegram bot!',
|
||||
E'Congratulations!\nYou have just connect your account to your vessel, @postgsail_bot.\n'),
|
||||
('no_vessel',
|
||||
'PostgSail add your boat',
|
||||
E'Hello __RECIPIENT__,\nYou created an account on PostgSail but you have not added your boat yet.\nIf you need any assistance, I would be happy to help. It is free and an open-source.\nFrancois',
|
||||
'PostgSail next step',
|
||||
E'Hello,\nYou should create your vessel. Check your email!\n'),
|
||||
('no_metadata',
|
||||
'PostgSail connect your boat',
|
||||
E'Hello __RECIPIENT__,\nYou created an account on PostgSail but you have not connected your boat yet.\nIf you need any assistance, I would be happy to help. It is free and an open-source.\nFrancois',
|
||||
'PostgSail next step',
|
||||
E'Hello,\nYou should connect your vessel. Check your email!\n'),
|
||||
('no_activity',
|
||||
'PostgSail boat inactivity',
|
||||
E'Hello __RECIPIENT__,\nWe don\'t see any activity on your account, do you need any assistance?\nIf you need any assistance, I would be happy to help. It is free and an open-source.\nFrancois.',
|
||||
'PostgSail inactivity!',
|
||||
E'We detected inactivity. Check your email!\n'),
|
||||
('deactivated',
|
||||
'PostgSail account deactivated',
|
||||
E'Hello __RECIPIENT__,\nYour account has been deactivated and all your data has been removed from PostgSail system.',
|
||||
'PostgSail deactivated!',
|
||||
E'We removed your account. Check your email!\n'),
|
||||
('grafana',
|
||||
'PostgSail Grafana integration',
|
||||
E'Hello __RECIPIENT__,\nCongratulations! You unlocked Grafana dashboard.\nSee more details at https://app.openplotter.cloud\nHappy sailing!\nFrancois',
|
||||
'PostgSail Grafana!',
|
||||
E'Congratulations!\nYou unlocked Grafana dashboard.\nSee more details at https://app.openplotter.cloud\n'),
|
||||
('windy',
|
||||
'PostgSail Windy Weather station',
|
||||
E'Hello __RECIPIENT__,\nCongratulations! Your boat is now a Windy Weather station.\nSee more details at __APP_URL__/windy\nHappy sailing!\nFrancois',
|
||||
'PostgSail Windy!',
|
||||
E'Congratulations!\nYour boat is now a Windy Weather station.\nSee more details at __APP_URL__/windy\n'),
|
||||
('alert',
|
||||
'PostgSail Alert',
|
||||
E'Hello __RECIPIENT__,\nWe detected an alert __ALERT__.\nSee more details at __APP_URL__\nStay safe.\nFrancois',
|
||||
'PostgSail Alert!',
|
||||
E'We detected an alert __ALERT__.\n');
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Queue handling
|
||||
--
|
||||
-- https://gist.github.com/kissgyorgy/beccba1291de962702ea9c237a900c79
|
||||
-- https://www.depesz.com/2012/06/13/how-to-send-mail-from-database/
|
||||
|
||||
-- Listen/Notify way
|
||||
--create function new_logbook_entry() returns trigger as $$
|
||||
--begin
|
||||
-- perform pg_notify('new_logbook_entry', NEW.id::text);
|
||||
-- return NEW;
|
||||
--END;
|
||||
--$$ language plpgsql;
|
||||
|
||||
-- table way
|
||||
CREATE TABLE IF NOT EXISTS public.process_queue (
|
||||
id INT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
channel TEXT NOT NULL,
|
||||
payload TEXT NOT NULL,
|
||||
ref_id TEXT NOT NULL,
|
||||
stored TIMESTAMPTZ NOT NULL,
|
||||
processed TIMESTAMPTZ DEFAULT NULL
|
||||
);
|
||||
-- Description
|
||||
COMMENT ON TABLE
|
||||
public.process_queue
|
||||
IS 'process queue for async job';
|
||||
-- Index
|
||||
CREATE INDEX ON public.process_queue (channel);
|
||||
CREATE INDEX ON public.process_queue (stored);
|
||||
CREATE INDEX ON public.process_queue (processed);
|
||||
|
||||
COMMENT ON COLUMN public.process_queue.ref_id IS 'either user_id or vessel_id';
|
||||
|
||||
-- Function process_queue helpers
|
||||
create function new_account_entry_fn() returns trigger as $new_account_entry$
|
||||
begin
|
||||
insert into process_queue (channel, payload, stored, ref_id) values ('new_account', NEW.email, now(), NEW.user_id);
|
||||
return NEW;
|
||||
END;
|
||||
$new_account_entry$ language plpgsql;
|
||||
|
||||
create function new_account_otp_validation_entry_fn() returns trigger as $new_account_otp_validation_entry$
|
||||
begin
|
||||
-- Add email_otp check only if not from oauth server
|
||||
if (NEW.preferences->>'email_verified')::boolean IS NOT True then
|
||||
insert into process_queue (channel, payload, stored, ref_id) values ('email_otp', NEW.email, now(), NEW.user_id);
|
||||
end if;
|
||||
return NEW;
|
||||
END;
|
||||
$new_account_otp_validation_entry$ language plpgsql;
|
||||
|
||||
create function new_vessel_entry_fn() returns trigger as $new_vessel_entry$
|
||||
begin
|
||||
insert into process_queue (channel, payload, stored, ref_id) values ('new_vessel', NEW.owner_email, now(), NEW.vessel_id);
|
||||
return NEW;
|
||||
END;
|
||||
$new_vessel_entry$ language plpgsql;
|
||||
|
||||
create function new_vessel_public_fn() returns trigger as $new_vessel_public$
|
||||
begin
|
||||
-- Update user settings with a public vessel name
|
||||
perform api.update_user_preferences_fn('{public_vessel}', regexp_replace(NEW.name, '\W+', '', 'g'));
|
||||
return NEW;
|
||||
END;
|
||||
$new_vessel_public$ language plpgsql;
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Tables Application Settings
|
||||
-- https://dba.stackexchange.com/questions/27296/storing-application-settings-with-different-datatypes#27297
|
||||
-- https://stackoverflow.com/questions/6893780/how-to-store-site-wide-settings-in-a-database
|
||||
-- http://cvs.savannah.gnu.org/viewvc/*checkout*/gnumed/gnumed/gnumed/server/sql/gmconfiguration.sql
|
||||
|
||||
CREATE TABLE IF NOT EXISTS public.app_settings (
|
||||
name TEXT NOT NULL UNIQUE,
|
||||
value TEXT NOT NULL
|
||||
);
|
||||
-- Description
|
||||
COMMENT ON TABLE public.app_settings IS 'application settings';
|
||||
COMMENT ON COLUMN public.app_settings.name IS 'application settings name key';
|
||||
COMMENT ON COLUMN public.app_settings.value IS 'application settings value';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Badges description
|
||||
--
|
||||
DROP TABLE IF EXISTS public.badges;
|
||||
CREATE TABLE IF NOT EXISTS public.badges(
|
||||
name TEXT UNIQUE,
|
||||
description TEXT
|
||||
);
|
||||
-- Description
|
||||
COMMENT ON TABLE
|
||||
public.badges
|
||||
IS 'Badges descriptions';
|
||||
|
||||
INSERT INTO badges VALUES
|
||||
('Helmsman',
|
||||
'Nice work logging your first sail! You are officially a helmsman now!'),
|
||||
('Wake Maker',
|
||||
'Yowzers! Welcome to the 15 knot+ club ya speed demon skipper!'),
|
||||
('Explorer',
|
||||
'It looks like home is where the helm is. Cheers to 10 days away from home port!'),
|
||||
('Mooring Pro',
|
||||
'It takes a lot of skill to "thread that floating needle" but seems like you have mastered mooring with 10 nights on buoy!'),
|
||||
('Anchormaster',
|
||||
'Hook, line and sinker, you have this anchoring thing down! 25 days on the hook for you!'),
|
||||
('Traveler todo',
|
||||
'Who needs to fly when one can sail! You are an international sailor. À votre santé!'),
|
||||
('Stormtrooper',
|
||||
'Just like the elite defenders of the Empire, here you are, our braving your own hydro-empire in windspeeds above 30kts. Nice work trooper! '),
|
||||
('Club Alaska',
|
||||
'Home to the bears, glaciers, midnight sun and high adventure. Welcome to the Club Alaska Captain!'),
|
||||
('Tropical Traveler',
|
||||
'Look at you with your suntan, tropical drink and southern latitude!'),
|
||||
('Aloha Award',
|
||||
'Ticking off over 2300 NM across the great blue Pacific makes you the rare recipient of the Aloha Award. Well done and Aloha sailor!'),
|
||||
('Navigator Award',
|
||||
'Woohoo! You made it, Ticking off over 100NM in one go, well done sailor!'),
|
||||
('Captain Award',
|
||||
'Congratulation, you reach over 1000NM, well done sailor!');
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- aistypes description
|
||||
--
|
||||
DROP TABLE IF EXISTS public.aistypes;
|
||||
CREATE TABLE IF NOT EXISTS aistypes(
|
||||
id NUMERIC UNIQUE,
|
||||
description TEXT
|
||||
);
|
||||
-- Description
|
||||
COMMENT ON TABLE
|
||||
public.aistypes
|
||||
IS 'aistypes AIS Ship Types, https://api.vesselfinder.com/docs/ref-aistypes.html';
|
||||
|
||||
INSERT INTO aistypes VALUES
|
||||
(0, 'Not available (default)'),
|
||||
(20, 'Wing in ground (WIG), all ships of this type'),
|
||||
(21, 'Wing in ground (WIG), Hazardous category A'),
|
||||
(22, 'Wing in ground (WIG), Hazardous category B'),
|
||||
(23, 'Wing in ground (WIG), Hazardous category C'),
|
||||
(24, 'Wing in ground (WIG), Hazardous category D'),
|
||||
(25, 'Wing in ground (WIG), Reserved for future use'),
|
||||
(26, 'Wing in ground (WIG), Reserved for future use'),
|
||||
(27, 'Wing in ground (WIG), Reserved for future use'),
|
||||
(28, 'Wing in ground (WIG), Reserved for future use'),
|
||||
(29, 'Wing in ground (WIG), Reserved for future use'),
|
||||
(30, 'Fishing'),
|
||||
(31, 'Towing'),
|
||||
(32, 'Towing: length exceeds 200m or breadth exceeds 25m'),
|
||||
(33, 'Dredging or underwater ops'),
|
||||
(34, 'Diving ops'),
|
||||
(35, 'Military ops'),
|
||||
(36, 'Sailing'),
|
||||
(37, 'Pleasure Craft'),
|
||||
(38, 'Reserved'),
|
||||
(39, 'Reserved'),
|
||||
(40, 'High speed craft (HSC), all ships of this type'),
|
||||
(41, 'High speed craft (HSC), Hazardous category A'),
|
||||
(42, 'High speed craft (HSC), Hazardous category B'),
|
||||
(43, 'High speed craft (HSC), Hazardous category C'),
|
||||
(44, 'High speed craft (HSC), Hazardous category D'),
|
||||
(45, 'High speed craft (HSC), Reserved for future use'),
|
||||
(46, 'High speed craft (HSC), Reserved for future use'),
|
||||
(47, 'High speed craft (HSC), Reserved for future use'),
|
||||
(48, 'High speed craft (HSC), Reserved for future use'),
|
||||
(49, 'High speed craft (HSC), No additional information'),
|
||||
(50, 'Pilot Vessel'),
|
||||
(51, 'Search and Rescue vessel'),
|
||||
(52, 'Tug'),
|
||||
(53, 'Port Tender'),
|
||||
(54, 'Anti-pollution equipment'),
|
||||
(55, 'Law Enforcement'),
|
||||
(56, 'Spare - Local Vessel'),
|
||||
(57, 'Spare - Local Vessel'),
|
||||
(58, 'Medical Transport'),
|
||||
(59, 'Noncombatant ship according to RR Resolution No. 18'),
|
||||
(60, 'Passenger, all ships of this type'),
|
||||
(61, 'Passenger, Hazardous category A'),
|
||||
(62, 'Passenger, Hazardous category B'),
|
||||
(63, 'Passenger, Hazardous category C'),
|
||||
(64, 'Passenger, Hazardous category D'),
|
||||
(65, 'Passenger, Reserved for future use'),
|
||||
(66, 'Passenger, Reserved for future use'),
|
||||
(67, 'Passenger, Reserved for future use'),
|
||||
(68, 'Passenger, Reserved for future use'),
|
||||
(69, 'Passenger, No additional information'),
|
||||
(70, 'Cargo, all ships of this type'),
|
||||
(71, 'Cargo, Hazardous category A'),
|
||||
(72, 'Cargo, Hazardous category B'),
|
||||
(73, 'Cargo, Hazardous category C'),
|
||||
(74, 'Cargo, Hazardous category D'),
|
||||
(75, 'Cargo, Reserved for future use'),
|
||||
(76, 'Cargo, Reserved for future use'),
|
||||
(77, 'Cargo, Reserved for future use'),
|
||||
(78, 'Cargo, Reserved for future use'),
|
||||
(79, 'Cargo, No additional information'),
|
||||
(80, 'Tanker, all ships of this type'),
|
||||
(81, 'Tanker, Hazardous category A'),
|
||||
(82, 'Tanker, Hazardous category B'),
|
||||
(83, 'Tanker, Hazardous category C'),
|
||||
(84, 'Tanker, Hazardous category D'),
|
||||
(85, 'Tanker, Reserved for future use'),
|
||||
(86, 'Tanker, Reserved for future use'),
|
||||
(87, 'Tanker, Reserved for future use'),
|
||||
(88, 'Tanker, Reserved for future use'),
|
||||
(89, 'Tanker, No additional information'),
|
||||
(90, 'Other Type, all ships of this type'),
|
||||
(91, 'Other Type, Hazardous category A'),
|
||||
(92, 'Other Type, Hazardous category B'),
|
||||
(93, 'Other Type, Hazardous category C'),
|
||||
(94, 'Other Type, Hazardous category D'),
|
||||
(95, 'Other Type, Reserved for future use'),
|
||||
(96, 'Other Type, Reserved for future use'),
|
||||
(97, 'Other Type, Reserved for future use'),
|
||||
(98, 'Other Type, Reserved for future use'),
|
||||
(99, 'Other Type, no additional information');
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- MMSI MID Codes
|
||||
--
|
||||
DROP TABLE IF EXISTS public.mid;
|
||||
CREATE TABLE IF NOT EXISTS public.mid(
|
||||
country TEXT,
|
||||
id NUMERIC UNIQUE,
|
||||
country_id INTEGER
|
||||
);
|
||||
-- Description
|
||||
COMMENT ON TABLE
|
||||
public.mid
|
||||
IS 'MMSI MID Codes (Maritime Mobile Service Identity) Filtered by Flag of Registration, https://www.marinevesseltraffic.com/2013/11/mmsi-mid-codes-by-flag.html';
|
||||
|
||||
INSERT INTO mid VALUES
|
||||
('Adelie Land', 501, NULL),
|
||||
('Afghanistan', 401, 4),
|
||||
('Alaska', 303, 840),
|
||||
('Albania', 201, 8),
|
||||
('Algeria', 605, 12),
|
||||
('American Samoa', 559, 16),
|
||||
('Andorra', 202, 20),
|
||||
('Angola', 603, 24),
|
||||
('Anguilla', 301, 660),
|
||||
('Antigua and Barbuda', 304, 28),
|
||||
('Antigua and Barbuda', 305, 28),
|
||||
('Argentina', 701, 32),
|
||||
('Armenia', 216, 51),
|
||||
('Aruba', 307, 533),
|
||||
('Ascension Island', 608, NULL),
|
||||
('Australia', 503, 36),
|
||||
('Austria', 203, 40),
|
||||
('Azerbaijan', 423, 31),
|
||||
('Azores', 204, NULL),
|
||||
('Bahamas', 308, 44),
|
||||
('Bahamas', 309, 44),
|
||||
('Bahamas', 311, 44),
|
||||
('Bahrain', 408, 48),
|
||||
('Bangladesh', 405, 50),
|
||||
('Barbados', 314, 52),
|
||||
('Belarus', 206, 112),
|
||||
('Belgium', 205, 56),
|
||||
('Belize', 312, 84),
|
||||
('Benin', 610, 204),
|
||||
('Bermuda', 310, 60),
|
||||
('Bhutan', 410, 64),
|
||||
('Bolivia', 720, 68),
|
||||
('Bosnia and Herzegovina', 478, 70),
|
||||
('Botswana', 611, 72),
|
||||
('Brazil', 710, 76),
|
||||
('British Virgin Islands', 378, 92),
|
||||
('Brunei Darussalam', 508, 96),
|
||||
('Bulgaria', 207, 100),
|
||||
('Burkina Faso', 633, 854),
|
||||
('Burundi', 609, 108),
|
||||
('Cambodia', 514, 116),
|
||||
('Cambodia', 515, 116),
|
||||
('Cameroon', 613, 120),
|
||||
('Canada', 316, 124),
|
||||
('Cape Verde', 617, 132),
|
||||
('Cayman Islands', 319, 136),
|
||||
('Central African Republic', 612, 140),
|
||||
('Chad', 670, 148),
|
||||
('Chile', 725, 152),
|
||||
('China', 412, 156),
|
||||
('China', 413, 156),
|
||||
('China', 414, 156),
|
||||
('Christmas Island', 516, 162),
|
||||
('Cocos Islands', 523, 166),
|
||||
('Colombia', 730, 170),
|
||||
('Comoros', 616, 174),
|
||||
('Comoros', 620, 174),
|
||||
('Congo', 615, 178),
|
||||
('Cook Islands', 518, 184),
|
||||
('Costa Rica', 321, 188),
|
||||
(E'Côte d\'Ivoire', 619, 384),
|
||||
('Croatia', 238, 191),
|
||||
('Crozet Archipelago', 618, NULL),
|
||||
('Cuba', 323, 192),
|
||||
('Cyprus', 209, 196),
|
||||
('Cyprus', 210, 196),
|
||||
('Cyprus', 212, 196),
|
||||
('Czech Republic', 270, 203),
|
||||
('Denmark', 219, 208),
|
||||
('Denmark', 220, 208),
|
||||
('Djibouti', 621, 262),
|
||||
('Dominica', 325, 212),
|
||||
('Dominican Republic', 327, 214),
|
||||
('DR Congo', 676, NULL),
|
||||
('Ecuador', 735, 218),
|
||||
('Egypt', 622, 818),
|
||||
('El Salvador', 359, 222),
|
||||
('Equatorial Guinea', 631, 226),
|
||||
('Eritrea', 625, 232),
|
||||
('Estonia', 276, 233),
|
||||
('Ethiopia', 624, 231),
|
||||
('Falkland Islands', 740, 234),
|
||||
('Faroe Islands', 231, NULL),
|
||||
('Fiji', 520, 242),
|
||||
('Finland', 230, 246),
|
||||
('France', 226, 250),
|
||||
('France', 227, 250),
|
||||
('France', 228, 250),
|
||||
('French Polynesia', 546, 260),
|
||||
('Gabonese Republic', 626, 266),
|
||||
('Gambia', 629, 270),
|
||||
('Georgia', 213, 268),
|
||||
('Germany', 211, 276),
|
||||
('Germany', 218, 276),
|
||||
('Ghana', 627, 288),
|
||||
('Gibraltar', 236, 292),
|
||||
('Greece', 237, 300),
|
||||
('Greece', 239, 300),
|
||||
('Greece', 240, 300),
|
||||
('Greece', 241, 300),
|
||||
('Greenland', 331, 304),
|
||||
('Grenada', 330, 308),
|
||||
('Guadeloupe', 329, 312),
|
||||
('Guatemala', 332, 320),
|
||||
('Guiana', 745, 324),
|
||||
('Guinea', 632, 324),
|
||||
('Guinea-Bissau', 630, 624),
|
||||
('Guyana', 750, 328),
|
||||
('Haiti', 336, 332),
|
||||
('Honduras', 334, 340),
|
||||
('Hong Kong', 477, 344),
|
||||
('Hungary', 243, 348),
|
||||
('Iceland', 251, 352),
|
||||
('India', 419, 356),
|
||||
('Indonesia', 525, 360),
|
||||
('Iran', 422, 364),
|
||||
('Iraq', 425, 368),
|
||||
('Ireland', 250, 372),
|
||||
('Israel', 428, 376),
|
||||
('Italy', 247, 380),
|
||||
('Jamaica', 339, 388),
|
||||
('Japan', 431, 392),
|
||||
('Japan', 432, 392),
|
||||
('Jordan', 438, 400),
|
||||
('Kazakhstan', 436, 398),
|
||||
('Kenya', 634, 404),
|
||||
('Kerguelen Islands', 635, NULL),
|
||||
('Kiribati', 529, 296),
|
||||
('Kuwait', 447, 414),
|
||||
('Kyrgyzstan', 451, 417),
|
||||
('Lao', 531, 418),
|
||||
('Latvia', 275, 428),
|
||||
('Lebanon', 450, 422),
|
||||
('Lesotho', 644, 426),
|
||||
('Liberia', 636, 430),
|
||||
('Liberia', 637, 430),
|
||||
('Libya', 642, 434),
|
||||
('Liechtenstein', 252, 438),
|
||||
('Lithuania', 277, 440),
|
||||
('Luxembourg', 253, 442),
|
||||
('Macao', 453, 446),
|
||||
('Madagascar', 647, 450),
|
||||
('Madeira', 255, NULL),
|
||||
('Makedonia', 274, NULL),
|
||||
('Malawi', 655, 454),
|
||||
('Malaysia', 533, 458),
|
||||
('Maldives', 455, 462),
|
||||
('Mali', 649, 466),
|
||||
('Malta', 215, 470),
|
||||
('Malta', 229, 470),
|
||||
('Malta', 248, 470),
|
||||
('Malta', 249, 470),
|
||||
('Malta', 256, 470),
|
||||
('Marshall Islands', 538, 584),
|
||||
('Martinique', 347, 474),
|
||||
('Mauritania', 654, 478),
|
||||
('Mauritius', 645, 480),
|
||||
('Mexico', 345, 484),
|
||||
('Micronesia', 510, 583),
|
||||
('Moldova', 214, 498),
|
||||
('Monaco', 254, 492),
|
||||
('Mongolia', 457, 496),
|
||||
('Montenegro', 262, 499),
|
||||
('Montserrat', 348, 500),
|
||||
('Morocco', 242, 504),
|
||||
('Mozambique', 650, 508),
|
||||
('Myanmar', 506, 104),
|
||||
('Namibia', 659, 516),
|
||||
('Nauru', 544, 520),
|
||||
('Nepal', 459, 524),
|
||||
('Netherlands', 244, 528),
|
||||
('Netherlands', 245, 528),
|
||||
('Netherlands', 246, 528),
|
||||
('Netherlands Antilles', 306, NULL),
|
||||
('New Caledonia', 540, 540),
|
||||
('New Zealand', 512, 554),
|
||||
('Nicaragua', 350, 558),
|
||||
('Niger', 656, 562),
|
||||
('Nigeria', 657, 566),
|
||||
('Niue', 542, 570),
|
||||
('North Korea', 445, 408),
|
||||
('Northern Mariana Islands', 536, 580),
|
||||
('Norway', 257, 578),
|
||||
('Norway', 258, 578),
|
||||
('Norway', 259, 578),
|
||||
('Oman', 461, 512),
|
||||
('Pakistan', 463, 586),
|
||||
('Palau', 511, 585),
|
||||
('Palestine', 443, 275),
|
||||
('Panama', 351, 591),
|
||||
('Panama', 352, 591),
|
||||
('Panama', 353, 591),
|
||||
('Panama', 354, 591),
|
||||
('Panama', 355, 591),
|
||||
('Panama', 356, 591),
|
||||
('Panama', 357, 591),
|
||||
('Panama', 370, 591),
|
||||
('Panama', 371, 591),
|
||||
('Panama', 372, 591),
|
||||
('Panama', 373, 591),
|
||||
('Papua New Guinea', 553, 598),
|
||||
('Paraguay', 755, 600),
|
||||
('Peru', 760, 604),
|
||||
('Philippines', 548, 608),
|
||||
('Pitcairn Island', 555, 612),
|
||||
('Poland', 261, 616),
|
||||
('Portugal', 263, 620),
|
||||
('Puerto Rico', 358, 630),
|
||||
('Qatar', 466, 634),
|
||||
('Reunion', 660, 638),
|
||||
('Romania', 264, 642),
|
||||
('Russian Federation', 273, 643),
|
||||
('Rwanda', 661, 646),
|
||||
('Saint Helena', 665, 654),
|
||||
('Saint Kitts and Nevis', 341, 659),
|
||||
('Saint Lucia', 343, 662),
|
||||
('Saint Paul and Amsterdam Islands', 607, NULL),
|
||||
('Saint Pierre and Miquelon', 361, 666),
|
||||
('Samoa', 561, 882),
|
||||
('San Marino', 268, 674),
|
||||
('Sao Tome and Principe', 668, 678),
|
||||
('Saudi Arabia', 403, 682),
|
||||
('Senegal', 663, 686),
|
||||
('Serbia', 279, 688),
|
||||
('Seychelles', 664, 690),
|
||||
('Sierra Leone', 667, 694),
|
||||
('Singapore', 563, 702),
|
||||
('Singapore', 564, 702),
|
||||
('Singapore', 565, 702),
|
||||
('Singapore', 566, 702),
|
||||
('Slovakia', 267, 703),
|
||||
('Slovenia', 278, 705),
|
||||
('Solomon Islands', 557, 90),
|
||||
('Somalia', 666, 706),
|
||||
('South Africa', 601, 710),
|
||||
('South Korea', 440, 410),
|
||||
('South Korea', 441, 410),
|
||||
('South Sudan', 638, 728),
|
||||
('Spain', 224, 724),
|
||||
('Spain', 225, 724),
|
||||
('Sri Lanka', 417, 144),
|
||||
('St Vincent and the Grenadines', 375, 670),
|
||||
('St Vincent and the Grenadines', 376, 670),
|
||||
('St Vincent and the Grenadines', 377, 670),
|
||||
('Sudan', 662, 729),
|
||||
('Suriname', 765, 740),
|
||||
('Swaziland', 669, 748),
|
||||
('Sweden', 265, 752),
|
||||
('Sweden', 266, 752),
|
||||
('Switzerland', 269, 756),
|
||||
('Syria', 468, 760),
|
||||
('Taiwan', 416, 158),
|
||||
('Tajikistan', 472, 762),
|
||||
('Tanzania', 674, 834),
|
||||
('Tanzania', 677, 834),
|
||||
('Thailand', 567, 764),
|
||||
('Togolese', 671, 768),
|
||||
('Tonga', 570, 776),
|
||||
('Trinidad and Tobago', 362, 780),
|
||||
('Tunisia', 672, 788),
|
||||
('Turkey', 271, 792),
|
||||
('Turkmenistan', 434, 795),
|
||||
('Turks and Caicos Islands', 364, 796),
|
||||
('Tuvalu', 572, 798),
|
||||
('Uganda', 675, 800),
|
||||
('Ukraine', 272, 804),
|
||||
('United Arab Emirates', 470, 784),
|
||||
('United Kingdom', 232, 826),
|
||||
('United Kingdom', 233, 826),
|
||||
('United Kingdom', 234, 826),
|
||||
('United Kingdom', 235, 826),
|
||||
('Uruguay', 770, 858),
|
||||
('US Virgin Islands', 379, 850),
|
||||
('USA', 338, 840),
|
||||
('USA', 366, 840),
|
||||
('USA', 367, 840),
|
||||
('USA', 368, 840),
|
||||
('USA', 369, 840),
|
||||
('Uzbekistan', 437, 860),
|
||||
('Vanuatu', 576, 548),
|
||||
('Vanuatu', 577, 548),
|
||||
('Vatican City', 208, NULL),
|
||||
('Venezuela', 775, 862),
|
||||
('Vietnam', 574, 704),
|
||||
('Wallis and Futuna Islands', 578, 876),
|
||||
('Yemen', 473, 887),
|
||||
('Yemen', 475, 887),
|
||||
('Zambia', 678, 894),
|
||||
('Zimbabwe', 679, 716);
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
--
|
||||
DROP TABLE IF EXISTS public.iso3166;
|
||||
CREATE TABLE IF NOT EXISTS public.iso3166(
|
||||
id INTEGER,
|
||||
country TEXT,
|
||||
alpha_2 TEXT,
|
||||
alpha_3 TEXT
|
||||
);
|
||||
-- Description
|
||||
COMMENT ON TABLE
|
||||
public.iso3166
|
||||
IS 'This is a complete list of all country ISO codes as described in the ISO 3166 international standard. Country Codes Alpha-2 & Alpha-3 https://www.iban.com/country-codes';
|
||||
|
||||
INSERT INTO iso3166 VALUES
|
||||
(4,'Afghanistan','AF','AFG'),
|
||||
(8,'Albania','AL','ALB'),
|
||||
(12,'Algeria','DZ','DZA'),
|
||||
(16,'American Samoa','AS','ASM'),
|
||||
(20,'Andorra','AD','AND'),
|
||||
(24,'Angola','AO','AGO'),
|
||||
(660,'Anguilla','AI','AIA'),
|
||||
(10,'Antarctica','AQ','ATA'),
|
||||
(28,'Antigua and Barbuda','AG','ATG'),
|
||||
(32,'Argentina','AR','ARG'),
|
||||
(51,'Armenia','AM','ARM'),
|
||||
(533,'Aruba','AW','ABW'),
|
||||
(36,'Australia','AU','AUS'),
|
||||
(40,'Austria','AT','AUT'),
|
||||
(31,'Azerbaijan','AZ','AZE'),
|
||||
(44,'Bahamas (the)','BS','BHS'),
|
||||
(48,'Bahrain','BH','BHR'),
|
||||
(50,'Bangladesh','BD','BGD'),
|
||||
(52,'Barbados','BB','BRB'),
|
||||
(112,'Belarus','BY','BLR'),
|
||||
(56,'Belgium','BE','BEL'),
|
||||
(84,'Belize','BZ','BLZ'),
|
||||
(204,'Benin','BJ','BEN'),
|
||||
(60,'Bermuda','BM','BMU'),
|
||||
(64,'Bhutan','BT','BTN'),
|
||||
(68,E'Bolivia (Plurinational State of)','BO','BOL'),
|
||||
(535,'Bonaire, Sint Eustatius and Saba','BQ','BES'),
|
||||
(70,'Bosnia and Herzegovina','BA','BIH'),
|
||||
(72,'Botswana','BW','BWA'),
|
||||
(74,'Bouvet Island','BV','BVT'),
|
||||
(76,'Brazil','BR','BRA'),
|
||||
(86,E'British Indian Ocean Territory (the)','IO','IOT'),
|
||||
(96,'Brunei Darussalam','BN','BRN'),
|
||||
(100,'Bulgaria','BG','BGR'),
|
||||
(854,'Burkina Faso','BF','BFA'),
|
||||
(108,'Burundi','BI','BDI'),
|
||||
(132,'Cabo Verde','CV','CPV'),
|
||||
(116,'Cambodia','KH','KHM'),
|
||||
(120,'Cameroon','CM','CMR'),
|
||||
(124,'Canada','CA','CAN'),
|
||||
(136,E'Cayman Islands (the)','KY','CYM'),
|
||||
(140,E'Central African Republic (the)','CF','CAF'),
|
||||
(148,'Chad','TD','TCD'),
|
||||
(152,'Chile','CL','CHL'),
|
||||
(156,'China','CN','CHN'),
|
||||
(162,'Christmas Island','CX','CXR'),
|
||||
(166,E'Cocos (Keeling) Islands (the)','CC','CCK'),
|
||||
(170,'Colombia','CO','COL'),
|
||||
(174,'Comoros (the)','KM','COM'),
|
||||
(180,E'Congo (the Democratic Republic of the)','CD','COD'),
|
||||
(178,E'Congo (the)','CG','COG'),
|
||||
(184,E'Cook Islands (the)','CK','COK'),
|
||||
(188,'Costa Rica','CR','CRI'),
|
||||
(191,'Croatia','HR','HRV'),
|
||||
(192,'Cuba','CU','CUB'),
|
||||
(531,'Curaçao','CW','CUW'),
|
||||
(196,'Cyprus','CY','CYP'),
|
||||
(203,'Czechia','CZ','CZE'),
|
||||
(384,E'Côte d\'Ivoire','CI','CIV'),
|
||||
(208,'Denmark','DK','DNK'),
|
||||
(262,'Djibouti','DJ','DJI'),
|
||||
(212,'Dominica','DM','DMA'),
|
||||
(214,E'Dominican Republic (the)','DO','DOM'),
|
||||
(218,'Ecuador','EC','ECU'),
|
||||
(818,'Egypt','EG','EGY'),
|
||||
(222,'El Salvador','SV','SLV'),
|
||||
(226,'Equatorial Guinea','GQ','GNQ'),
|
||||
(232,'Eritrea','ER','ERI'),
|
||||
(233,'Estonia','EE','EST'),
|
||||
(748,'Eswatini','SZ','SWZ'),
|
||||
(231,'Ethiopia','ET','ETH'),
|
||||
(238,E'Falkland Islands (the) [Malvinas]','FK','FLK'),
|
||||
(234,E'Faroe Islands (the)','FO','FRO'),
|
||||
(242,'Fiji','FJ','FJI'),
|
||||
(246,'Finland','FI','FIN'),
|
||||
(250,'France','FR','FRA'),
|
||||
(254,'French Guiana','GF','GUF'),
|
||||
(258,'French Polynesia','PF','PYF'),
|
||||
(260,E'French Southern Territories (the)','TF','ATF'),
|
||||
(266,'Gabon','GA','GAB'),
|
||||
(270,E'Gambia (the)','GM','GMB'),
|
||||
(268,'Georgia','GE','GEO'),
|
||||
(276,'Germany','DE','DEU'),
|
||||
(288,'Ghana','GH','GHA'),
|
||||
(292,'Gibraltar','GI','GIB'),
|
||||
(300,'Greece','GR','GRC'),
|
||||
(304,'Greenland','GL','GRL'),
|
||||
(308,'Grenada','GD','GRD'),
|
||||
(312,'Guadeloupe','GP','GLP'),
|
||||
(316,'Guam','GU','GUM'),
|
||||
(320,'Guatemala','GT','GTM'),
|
||||
(831,'Guernsey','GG','GGY'),
|
||||
(324,'Guinea','GN','GIN'),
|
||||
(624,'Guinea-Bissau','GW','GNB'),
|
||||
(328,'Guyana','GY','GUY'),
|
||||
(332,'Haiti','HT','HTI'),
|
||||
(334,'Heard Island and McDonald Islands','HM','HMD'),
|
||||
(336,E'Holy See (the)','VA','VAT'),
|
||||
(340,'Honduras','HN','HND'),
|
||||
(344,'Hong Kong','HK','HKG'),
|
||||
(348,'Hungary','HU','HUN'),
|
||||
(352,'Iceland','IS','ISL'),
|
||||
(356,'India','IN','IND'),
|
||||
(360,'Indonesia','ID','IDN'),
|
||||
(364,E'Iran (Islamic Republic of)','IR','IRN'),
|
||||
(368,'Iraq','IQ','IRQ'),
|
||||
(372,'Ireland','IE','IRL'),
|
||||
(833,'Isle of Man','IM','IMN'),
|
||||
(376,'Israel','IL','ISR'),
|
||||
(380,'Italy','IT','ITA'),
|
||||
(388,'Jamaica','JM','JAM'),
|
||||
(392,'Japan','JP','JPN'),
|
||||
(832,'Jersey','JE','JEY'),
|
||||
(400,'Jordan','JO','JOR'),
|
||||
(398,'Kazakhstan','KZ','KAZ'),
|
||||
(404,'Kenya','KE','KEN'),
|
||||
(296,'Kiribati','KI','KIR'),
|
||||
(408,E'Korea (the Democratic People\'s Republic of)','KP','PRK'),
|
||||
(410,E'Korea (the Republic of)','KR','KOR'),
|
||||
(414,'Kuwait','KW','KWT'),
|
||||
(417,'Kyrgyzstan','KG','KGZ'),
|
||||
(418,E'Lao People\'s Democratic Republic (the)','LA','LAO'),
|
||||
(428,'Latvia','LV','LVA'),
|
||||
(422,'Lebanon','LB','LBN'),
|
||||
(426,'Lesotho','LS','LSO'),
|
||||
(430,'Liberia','LR','LBR'),
|
||||
(434,'Libya','LY','LBY'),
|
||||
(438,'Liechtenstein','LI','LIE'),
|
||||
(440,'Lithuania','LT','LTU'),
|
||||
(442,'Luxembourg','LU','LUX'),
|
||||
(446,'Macao','MO','MAC'),
|
||||
(450,'Madagascar','MG','MDG'),
|
||||
(454,'Malawi','MW','MWI'),
|
||||
(458,'Malaysia','MY','MYS'),
|
||||
(462,'Maldives','MV','MDV'),
|
||||
(466,'Mali','ML','MLI'),
|
||||
(470,'Malta','MT','MLT'),
|
||||
(584,E'Marshall Islands (the)','MH','MHL'),
|
||||
(474,'Martinique','MQ','MTQ'),
|
||||
(478,'Mauritania','MR','MRT'),
|
||||
(480,'Mauritius','MU','MUS'),
|
||||
(175,'Mayotte','YT','MYT'),
|
||||
(484,'Mexico','MX','MEX'),
|
||||
(583,E'Micronesia (Federated States of)','FM','FSM'),
|
||||
(498,E'Moldova (the Republic of)','MD','MDA'),
|
||||
(492,'Monaco','MC','MCO'),
|
||||
(496,'Mongolia','MN','MNG'),
|
||||
(499,'Montenegro','ME','MNE'),
|
||||
(500,'Montserrat','MS','MSR'),
|
||||
(504,'Morocco','MA','MAR'),
|
||||
(508,'Mozambique','MZ','MOZ'),
|
||||
(104,'Myanmar','MM','MMR'),
|
||||
(516,'Namibia','NA','NAM'),
|
||||
(520,'Nauru','NR','NRU'),
|
||||
(524,'Nepal','NP','NPL'),
|
||||
(528,E'Netherlands (the)','NL','NLD'),
|
||||
(540,'New Caledonia','NC','NCL'),
|
||||
(554,'New Zealand','NZ','NZL'),
|
||||
(558,'Nicaragua','NI','NIC'),
|
||||
(562,E'Niger (the)','NE','NER'),
|
||||
(566,'Nigeria','NG','NGA'),
|
||||
(570,'Niue','NU','NIU'),
|
||||
(574,'Norfolk Island','NF','NFK'),
|
||||
(580,E'Northern Mariana Islands (the)','MP','MNP'),
|
||||
(578,'Norway','NO','NOR'),
|
||||
(512,'Oman','OM','OMN'),
|
||||
(586,'Pakistan','PK','PAK'),
|
||||
(585,'Palau','PW','PLW'),
|
||||
(275,'Palestine, State of','PS','PSE'),
|
||||
(591,'Panama','PA','PAN'),
|
||||
(598,'Papua New Guinea','PG','PNG'),
|
||||
(600,'Paraguay','PY','PRY'),
|
||||
(604,'Peru','PE','PER'),
|
||||
(608,E'Philippines (the)','PH','PHL'),
|
||||
(612,'Pitcairn','PN','PCN'),
|
||||
(616,'Poland','PL','POL'),
|
||||
(620,'Portugal','PT','PRT'),
|
||||
(630,'Puerto Rico','PR','PRI'),
|
||||
(634,'Qatar','QA','QAT'),
|
||||
(807,'Republic of North Macedonia','MK','MKD'),
|
||||
(642,'Romania','RO','ROU'),
|
||||
(643,'Russian Federation (the)','RU','RUS'),
|
||||
(646,'Rwanda','RW','RWA'),
|
||||
(638,'Réunion','RE','REU'),
|
||||
(652,'Saint Barthélemy','BL','BLM'),
|
||||
(654,'Saint Helena, Ascension and Tristan da Cunha','SH','SHN'),
|
||||
(659,'Saint Kitts and Nevis','KN','KNA'),
|
||||
(662,'Saint Lucia','LC','LCA'),
|
||||
(663,'Saint Martin (French part)','MF','MAF'),
|
||||
(666,'Saint Pierre and Miquelon','PM','SPM'),
|
||||
(670,'Saint Vincent and the Grenadines','VC','VCT'),
|
||||
(882,'Samoa','WS','WSM'),
|
||||
(674,'San Marino','SM','SMR'),
|
||||
(678,'Sao Tome and Principe','ST','STP'),
|
||||
(682,'Saudi Arabia','SA','SAU'),
|
||||
(686,'Senegal','SN','SEN'),
|
||||
(688,'Serbia','RS','SRB'),
|
||||
(690,'Seychelles','SC','SYC'),
|
||||
(694,'Sierra Leone','SL','SLE'),
|
||||
(702,'Singapore','SG','SGP'),
|
||||
(534,'Sint Maarten (Dutch part)','SX','SXM'),
|
||||
(703,'Slovakia','SK','SVK'),
|
||||
(705,'Slovenia','SI','SVN'),
|
||||
(90,'Solomon Islands','SB','SLB'),
|
||||
(706,'Somalia','SO','SOM'),
|
||||
(710,'South Africa','ZA','ZAF'),
|
||||
(239,'South Georgia and the South Sandwich Islands','GS','SGS'),
|
||||
(728,'South Sudan','SS','SSD'),
|
||||
(724,'Spain','ES','ESP'),
|
||||
(144,'Sri Lanka','LK','LKA'),
|
||||
(729,'Sudan (the)','SD','SDN'),
|
||||
(740,'Suriname','SR','SUR'),
|
||||
(744,'Svalbard and Jan Mayen','SJ','SJM'),
|
||||
(752,'Sweden','SE','SWE'),
|
||||
(756,'Switzerland','CH','CHE'),
|
||||
(760,'Syrian Arab Republic','SY','SYR'),
|
||||
(158,'Taiwan (Province of China)','TW','TWN'),
|
||||
(762,'Tajikistan','TJ','TJK'),
|
||||
(834,'Tanzania, United Republic of','TZ','TZA'),
|
||||
(764,'Thailand','TH','THA'),
|
||||
(626,'Timor-Leste','TL','TLS'),
|
||||
(768,'Togo','TG','TGO'),
|
||||
(772,'Tokelau','TK','TKL'),
|
||||
(776,'Tonga','TO','TON'),
|
||||
(780,'Trinidad and Tobago','TT','TTO'),
|
||||
(788,'Tunisia','TN','TUN'),
|
||||
(792,'Turkey','TR','TUR'),
|
||||
(795,'Turkmenistan','TM','TKM'),
|
||||
(796,'Turks and Caicos Islands (the)','TC','TCA'),
|
||||
(798,'Tuvalu','TV','TUV'),
|
||||
(800,'Uganda','UG','UGA'),
|
||||
(804,'Ukraine','UA','UKR'),
|
||||
(784,'United Arab Emirates (the)','AE','ARE'),
|
||||
(826,'United Kingdom of Great Britain and Northern Ireland (the)','GB','GBR'),
|
||||
(581,'United States Minor Outlying Islands (the)','UM','UMI'),
|
||||
(840,'United States of America (the)','US','USA'),
|
||||
(858,'Uruguay','UY','URY'),
|
||||
(860,'Uzbekistan','UZ','UZB'),
|
||||
(548,'Vanuatu','VU','VUT'),
|
||||
(862,'Venezuela (Bolivarian Republic of)','VE','VEN'),
|
||||
(704,'Viet Nam','VN','VNM'),
|
||||
(92,'Virgin Islands (British)','VG','VGB'),
|
||||
(850,'Virgin Islands (U.S.)','VI','VIR'),
|
||||
(876,'Wallis and Futuna','WF','WLF'),
|
||||
(732,'Western Sahara','EH','ESH'),
|
||||
(887,'Yemen','YE','YEM'),
|
||||
(894,'Zambia','ZM','ZMB'),
|
||||
(716,'Zimbabwe','ZW','ZWE'),
|
||||
(248,E'Åland Islands','AX','ALA');
|
1982
initdb/02_3_2_signalk_public_functions.sql
Normal file
1982
initdb/02_3_2_signalk_public_functions.sql
Normal file
File diff suppressed because it is too large
Load Diff
240
initdb/02_3_3_signalk_public_functions_helpers.sql
Normal file
240
initdb/02_3_3_signalk_public_functions_helpers.sql
Normal file
@@ -0,0 +1,240 @@
|
||||
---------------------------------------------------------------------------
|
||||
-- singalk db public schema
|
||||
--
|
||||
|
||||
-- List current database
|
||||
select current_database();
|
||||
|
||||
-- connect to the DB
|
||||
\c signalk
|
||||
|
||||
CREATE SCHEMA IF NOT EXISTS public;
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- basic helpers to check type and more
|
||||
--
|
||||
CREATE OR REPLACE FUNCTION public.isdouble(text) RETURNS BOOLEAN AS
|
||||
$isdouble$
|
||||
DECLARE x DOUBLE PRECISION;
|
||||
BEGIN
|
||||
x = $1::DOUBLE PRECISION;
|
||||
RETURN TRUE;
|
||||
EXCEPTION WHEN others THEN
|
||||
RETURN FALSE;
|
||||
END;
|
||||
$isdouble$
|
||||
STRICT
|
||||
LANGUAGE plpgsql IMMUTABLE;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.isdouble
|
||||
IS 'Check typeof value is double';
|
||||
|
||||
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';
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.isdate(s varchar) returns boolean as $$
|
||||
BEGIN
|
||||
perform s::date;
|
||||
return true;
|
||||
exception when others then
|
||||
return false;
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.isdate
|
||||
IS 'Check typeof value is date';
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.istimestamptz(text) RETURNS BOOLEAN AS
|
||||
$isdate$
|
||||
DECLARE x TIMESTAMPTZ;
|
||||
BEGIN
|
||||
x = $1::TIMESTAMPTZ;
|
||||
RETURN TRUE;
|
||||
EXCEPTION WHEN others THEN
|
||||
RETURN FALSE;
|
||||
END;
|
||||
$isdate$
|
||||
STRICT
|
||||
LANGUAGE plpgsql IMMUTABLE;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.istimestamptz
|
||||
IS 'Check typeof value is TIMESTAMPTZ';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- JSON helpers
|
||||
--
|
||||
CREATE FUNCTION jsonb_key_exists(some_json jsonb, outer_key text)
|
||||
RETURNS BOOLEAN AS $$
|
||||
BEGIN
|
||||
RETURN (some_json->outer_key) IS NOT NULL;
|
||||
END;
|
||||
$$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.jsonb_key_exists
|
||||
IS 'function that checks if an outer key exists in some_json and returns a boolean';
|
||||
|
||||
-- https://stackoverflow.com/questions/42944888/merging-jsonb-values-in-postgresql
|
||||
CREATE OR REPLACE FUNCTION public.jsonb_recursive_merge(A jsonb, B jsonb)
|
||||
RETURNS jsonb LANGUAGE SQL AS $$
|
||||
SELECT
|
||||
jsonb_object_agg(
|
||||
coalesce(ka, kb),
|
||||
CASE
|
||||
WHEN va isnull THEN vb
|
||||
WHEN vb isnull THEN va
|
||||
WHEN jsonb_typeof(va) <> 'object' OR jsonb_typeof(vb) <> 'object' THEN vb
|
||||
ELSE jsonb_recursive_merge(va, vb) END
|
||||
)
|
||||
FROM jsonb_each(A) temptable1(ka, va)
|
||||
FULL JOIN jsonb_each(B) temptable2(kb, vb) ON ka = kb
|
||||
$$;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.jsonb_recursive_merge
|
||||
IS 'Merging JSONB values';
|
||||
|
||||
-- https://stackoverflow.com/questions/36041784/postgresql-compare-two-jsonb-objects
|
||||
CREATE OR REPLACE FUNCTION public.jsonb_diff_val(val1 JSONB,val2 JSONB)
|
||||
RETURNS JSONB AS $jsonb_diff_val$
|
||||
DECLARE
|
||||
result JSONB;
|
||||
v RECORD;
|
||||
BEGIN
|
||||
result = val1;
|
||||
FOR v IN SELECT * FROM jsonb_each(val2) LOOP
|
||||
IF result @> jsonb_build_object(v.key,v.value)
|
||||
THEN result = result - v.key;
|
||||
ELSIF result ? v.key THEN CONTINUE;
|
||||
ELSE
|
||||
result = result || jsonb_build_object(v.key,'null');
|
||||
END IF;
|
||||
END LOOP;
|
||||
RETURN result;
|
||||
END;
|
||||
$jsonb_diff_val$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.jsonb_diff_val
|
||||
IS 'Compare two jsonb objects';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- uuid v7 helpers
|
||||
--
|
||||
-- https://gist.github.com/kjmph/5bd772b2c2df145aa645b837da7eca74
|
||||
CREATE OR REPLACE FUNCTION public.timestamp_from_uuid_v7(_uuid uuid)
|
||||
RETURNS timestamp without time zone
|
||||
LANGUAGE sql
|
||||
-- Based off IETF draft, https://datatracker.ietf.org/doc/draft-peabody-dispatch-new-uuid-format/
|
||||
IMMUTABLE PARALLEL SAFE STRICT LEAKPROOF
|
||||
AS $$
|
||||
SELECT to_timestamp(('x0000' || substr(_uuid::text, 1, 8) || substr(_uuid::text, 10, 4))::bit(64)::bigint::numeric / 1000);
|
||||
$$
|
||||
;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.timestamp_from_uuid_v7
|
||||
IS 'extract the timestamp from the uuid.';
|
||||
|
||||
create or replace function public.uuid_generate_v7()
|
||||
returns uuid
|
||||
as $$
|
||||
begin
|
||||
-- use random v4 uuid as starting point (which has the same variant we need)
|
||||
-- then overlay timestamp
|
||||
-- then set version 7 by flipping the 2 and 1 bit in the version 4 string
|
||||
return encode(
|
||||
set_bit(
|
||||
set_bit(
|
||||
overlay(uuid_send(gen_random_uuid())
|
||||
placing substring(int8send(floor(extract(epoch from clock_timestamp()) * 1000)::bigint) from 3)
|
||||
from 1 for 6
|
||||
),
|
||||
52, 1
|
||||
),
|
||||
53, 1
|
||||
),
|
||||
'hex')::uuid;
|
||||
end
|
||||
$$
|
||||
language plpgsql volatile;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.uuid_generate_v7
|
||||
IS 'Generate UUID v7, Based off IETF draft, https://datatracker.ietf.org/doc/draft-peabody-dispatch-new-uuid-format/';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Conversion helpers
|
||||
--
|
||||
CREATE OR REPLACE FUNCTION public.kelvinToCel(IN temperature NUMERIC)
|
||||
RETURNS NUMERIC
|
||||
AS $$
|
||||
BEGIN
|
||||
RETURN ROUND((((temperature)::numeric - 273.15) * 10) / 10);
|
||||
END
|
||||
$$
|
||||
LANGUAGE plpgsql IMMUTABLE;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.kelvinToCel
|
||||
IS 'convert kelvin To Celsius';
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.radiantToDegrees(IN angle NUMERIC)
|
||||
RETURNS NUMERIC
|
||||
AS $$
|
||||
BEGIN
|
||||
RETURN ROUND((((angle)::numeric * 57.2958) * 10) / 10);
|
||||
END
|
||||
$$
|
||||
LANGUAGE plpgsql IMMUTABLE;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.radiantToDegrees
|
||||
IS 'convert radiant To Degrees';
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.valToPercent(IN val NUMERIC)
|
||||
RETURNS NUMERIC
|
||||
AS $$
|
||||
BEGIN
|
||||
RETURN (val * 100);
|
||||
END
|
||||
$$
|
||||
LANGUAGE plpgsql IMMUTABLE;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.valToPercent
|
||||
IS 'convert radiant To Degrees';
|
859
initdb/02_3_3_signalk_public_functions_py.sql
Normal file
859
initdb/02_3_3_signalk_public_functions_py.sql
Normal file
@@ -0,0 +1,859 @@
|
||||
---------------------------------------------------------------------------
|
||||
-- singalk db public schema
|
||||
--
|
||||
|
||||
-- List current database
|
||||
select current_database();
|
||||
|
||||
-- connect to the DB
|
||||
\c signalk
|
||||
|
||||
CREATE SCHEMA IF NOT EXISTS public;
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- python reverse_geocode
|
||||
--
|
||||
-- https://github.com/CartoDB/labs-postgresql/blob/master/workshop/plpython.md
|
||||
--
|
||||
DROP FUNCTION IF EXISTS reverse_geocode_py_fn;
|
||||
CREATE OR REPLACE FUNCTION reverse_geocode_py_fn(IN geocoder TEXT, IN lon NUMERIC, IN lat NUMERIC,
|
||||
OUT geo JSONB)
|
||||
AS $reverse_geocode_py$
|
||||
import requests
|
||||
|
||||
# Use the shared cache to avoid preparing the geocoder metadata
|
||||
if geocoder in SD:
|
||||
plan = SD[geocoder]
|
||||
# A prepared statement from Python
|
||||
else:
|
||||
plan = plpy.prepare("SELECT reverse_url AS url FROM geocoders WHERE name = $1", ["text"])
|
||||
SD[geocoder] = plan
|
||||
|
||||
# Execute the statement with the geocoder param and limit to 1 result
|
||||
rv = plpy.execute(plan, [geocoder], 1)
|
||||
url = rv[0]['url']
|
||||
|
||||
# Validate input
|
||||
if not lon or not lat:
|
||||
plpy.notice('reverse_geocode_py_fn Parameters [{}] [{}]'.format(lon, lat))
|
||||
plpy.error('Error missing parameters')
|
||||
return None
|
||||
|
||||
def georeverse(geocoder, lon, lat, zoom="18"):
|
||||
# Make the request to the geocoder API
|
||||
# https://operations.osmfoundation.org/policies/nominatim/
|
||||
headers = {"Accept-Language": "en-US,en;q=0.5", "User-Agent": "PostgSail", "From": "xbgmsharp@gmail.com"}
|
||||
payload = {"lon": lon, "lat": lat, "format": "jsonv2", "zoom": zoom, "accept-language": "en"}
|
||||
# https://nominatim.org/release-docs/latest/api/Reverse/
|
||||
r = requests.get(url, headers=headers, params=payload)
|
||||
|
||||
# Parse response
|
||||
# If name is null fallback to address field tags: neighbourhood,suburb
|
||||
# if none repeat with lower zoom level
|
||||
if r.status_code == 200 and "name" in r.json():
|
||||
r_dict = r.json()
|
||||
#plpy.notice('reverse_geocode_py_fn Parameters [{}] [{}] Response'.format(lon, lat, r_dict))
|
||||
output = None
|
||||
country_code = None
|
||||
if "country_code" in r_dict["address"] and r_dict["address"]["country_code"]:
|
||||
country_code = r_dict["address"]["country_code"]
|
||||
if r_dict["name"]:
|
||||
return { "name": r_dict["name"], "country_code": country_code }
|
||||
elif "address" in r_dict and r_dict["address"]:
|
||||
if "neighbourhood" in r_dict["address"] and r_dict["address"]["neighbourhood"]:
|
||||
return { "name": r_dict["address"]["neighbourhood"], "country_code": country_code }
|
||||
elif "hamlet" in r_dict["address"] and r_dict["address"]["hamlet"]:
|
||||
return { "name": r_dict["address"]["hamlet"], "country_code": country_code }
|
||||
elif "suburb" in r_dict["address"] and r_dict["address"]["suburb"]:
|
||||
return { "name": r_dict["address"]["suburb"], "country_code": country_code }
|
||||
elif "residential" in r_dict["address"] and r_dict["address"]["residential"]:
|
||||
return { "name": r_dict["address"]["residential"], "country_code": country_code }
|
||||
elif "village" in r_dict["address"] and r_dict["address"]["village"]:
|
||||
return { "name": r_dict["address"]["village"], "country_code": country_code }
|
||||
elif "town" in r_dict["address"] and r_dict["address"]["town"]:
|
||||
return { "name": r_dict["address"]["town"], "country_code": country_code }
|
||||
elif "amenity" in r_dict["address"] and r_dict["address"]["amenity"]:
|
||||
return { "name": r_dict["address"]["amenity"], "country_code": country_code }
|
||||
else:
|
||||
if (zoom == 15):
|
||||
plpy.notice('georeverse recursive retry with lower zoom than:[{}], Response [{}]'.format(zoom , r.json()))
|
||||
return { "name": "n/a", "country_code": country_code }
|
||||
else:
|
||||
plpy.notice('georeverse recursive retry with lower zoom than:[{}], Response [{}]'.format(zoom , r.json()))
|
||||
return georeverse(geocoder, lon, lat, 15)
|
||||
else:
|
||||
return { "name": "n/a", "country_code": country_code }
|
||||
else:
|
||||
plpy.warning('Failed to received a geo full address %s', r.json())
|
||||
#plpy.error('Failed to received a geo full address %s', r.json())
|
||||
return { "name": "unknown", "country_code": "unknown" }
|
||||
|
||||
return georeverse(geocoder, lon, lat)
|
||||
$reverse_geocode_py$ TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.reverse_geocode_py_fn
|
||||
IS 'query reverse geo service to return location name using plpython3u';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- python send email
|
||||
--
|
||||
-- https://www.programcreek.com/python/example/3684/email.utils.formatdate
|
||||
DROP FUNCTION IF EXISTS send_email_py_fn;
|
||||
CREATE OR REPLACE FUNCTION send_email_py_fn(IN email_type TEXT, IN _user JSONB, IN app JSONB) RETURNS void
|
||||
AS $send_email_py$
|
||||
# Import smtplib for the actual sending function
|
||||
import smtplib
|
||||
|
||||
# Import the email modules we need
|
||||
#from email.message import EmailMessage
|
||||
from email.utils import formatdate,make_msgid
|
||||
from email.mime.text import MIMEText
|
||||
|
||||
# Use the shared cache to avoid preparing the email metadata
|
||||
if email_type in SD:
|
||||
plan = SD[email_type]
|
||||
# A prepared statement from Python
|
||||
else:
|
||||
plan = plpy.prepare("SELECT * FROM email_templates WHERE name = $1", ["text"])
|
||||
SD[email_type] = plan
|
||||
|
||||
# Execute the statement with the email_type param and limit to 1 result
|
||||
rv = plpy.execute(plan, [email_type], 1)
|
||||
email_subject = rv[0]['email_subject']
|
||||
email_content = rv[0]['email_content']
|
||||
|
||||
# Replace fields using input jsonb obj
|
||||
if not _user or not app:
|
||||
plpy.notice('send_email_py_fn Parameters [{}] [{}]'.format(_user, app))
|
||||
plpy.error('Error missing parameters')
|
||||
return None
|
||||
if 'logbook_name' in _user and _user['logbook_name']:
|
||||
email_content = email_content.replace('__LOGBOOK_NAME__', _user['logbook_name'])
|
||||
if 'logbook_link' in _user and _user['logbook_link']:
|
||||
email_content = email_content.replace('__LOGBOOK_LINK__', str(_user['logbook_link']))
|
||||
if 'recipient' in _user and _user['recipient']:
|
||||
email_content = email_content.replace('__RECIPIENT__', _user['recipient'])
|
||||
if 'boat' in _user and _user['boat']:
|
||||
email_content = email_content.replace('__BOAT__', _user['boat'])
|
||||
if 'badge' in _user and _user['badge']:
|
||||
email_content = email_content.replace('__BADGE_NAME__', _user['badge'])
|
||||
if 'otp_code' in _user and _user['otp_code']:
|
||||
email_content = email_content.replace('__OTP_CODE__', _user['otp_code'])
|
||||
if 'reset_qs' in _user and _user['reset_qs']:
|
||||
email_content = email_content.replace('__RESET_QS__', _user['reset_qs'])
|
||||
if 'alert' in _user and _user['alert']:
|
||||
email_content = email_content.replace('__ALERT__', _user['alert'])
|
||||
|
||||
if 'app.url' in app and app['app.url']:
|
||||
email_content = email_content.replace('__APP_URL__', app['app.url'])
|
||||
|
||||
email_from = 'root@localhost'
|
||||
if 'app.email_from' in app and app['app.email_from']:
|
||||
email_from = 'PostgSail <' + app['app.email_from'] + '>'
|
||||
#plpy.notice('Sending email from [{}] [{}]'.format(email_from, app['app.email_from']))
|
||||
|
||||
email_to = 'root@localhost'
|
||||
if 'email' in _user and _user['email']:
|
||||
email_to = _user['email']
|
||||
#plpy.notice('Sending email to [{}] [{}]'.format(email_to, _user['email']))
|
||||
else:
|
||||
plpy.error('Error email to')
|
||||
return None
|
||||
|
||||
msg = MIMEText(email_content, 'plain', 'utf-8')
|
||||
msg["Subject"] = email_subject
|
||||
msg["From"] = email_from
|
||||
msg["To"] = email_to
|
||||
msg["Date"] = formatdate()
|
||||
msg["Message-ID"] = make_msgid()
|
||||
|
||||
server_smtp = 'localhost'
|
||||
if 'app.email_server' in app and app['app.email_server']:
|
||||
server_smtp = app['app.email_server']
|
||||
#plpy.notice('Sending server [{}] [{}]'.format(server_smtp, app['app.email_server']))
|
||||
|
||||
# Send the message via our own SMTP server.
|
||||
try:
|
||||
# send your message with credentials specified above
|
||||
with smtplib.SMTP(server_smtp, 587) as server:
|
||||
if 'app.email_user' in app and app['app.email_user'] \
|
||||
and 'app.email_pass' in app and app['app.email_pass']:
|
||||
server.starttls()
|
||||
server.login(app['app.email_user'], app['app.email_pass'])
|
||||
#server.send_message(msg)
|
||||
server.sendmail(msg["From"], msg["To"], msg.as_string())
|
||||
server.quit()
|
||||
# tell the script to report if your message was sent or which errors need to be fixed
|
||||
plpy.notice('Sent email successfully to [{}] [{}]'.format(msg["To"], msg["Subject"]))
|
||||
return None
|
||||
except OSError as error:
|
||||
plpy.error('OS Error occurred: ' + str(error))
|
||||
except smtplib.SMTPConnectError:
|
||||
plpy.error('Failed to connect to the server. Bad connection settings?')
|
||||
except smtplib.SMTPServerDisconnected:
|
||||
plpy.error('Failed to connect to the server. Wrong user/password?')
|
||||
except smtplib.SMTPException as e:
|
||||
plpy.error('SMTP error occurred: ' + str(e))
|
||||
$send_email_py$ TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.send_email_py_fn
|
||||
IS 'Send email notification using plpython3u';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- python send pushover message
|
||||
-- https://pushover.net/
|
||||
DROP FUNCTION IF EXISTS send_pushover_py_fn;
|
||||
CREATE OR REPLACE FUNCTION send_pushover_py_fn(IN message_type TEXT, IN _user JSONB, IN app JSONB) RETURNS void
|
||||
AS $send_pushover_py$
|
||||
import requests
|
||||
|
||||
# Use the shared cache to avoid preparing the email metadata
|
||||
if message_type in SD:
|
||||
plan = SD[message_type]
|
||||
# A prepared statement from Python
|
||||
else:
|
||||
plan = plpy.prepare("SELECT * FROM email_templates WHERE name = $1", ["text"])
|
||||
SD[message_type] = plan
|
||||
|
||||
# Execute the statement with the message_type param and limit to 1 result
|
||||
rv = plpy.execute(plan, [message_type], 1)
|
||||
pushover_title = rv[0]['pushover_title']
|
||||
pushover_message = rv[0]['pushover_message']
|
||||
|
||||
# Replace fields using input jsonb obj
|
||||
if 'logbook_name' in _user and _user['logbook_name']:
|
||||
pushover_message = pushover_message.replace('__LOGBOOK_NAME__', _user['logbook_name'])
|
||||
if 'logbook_link' in _user and _user['logbook_link']:
|
||||
pushover_message = pushover_message.replace('__LOGBOOK_LINK__', str(_user['logbook_link']))
|
||||
if 'recipient' in _user and _user['recipient']:
|
||||
pushover_message = pushover_message.replace('__RECIPIENT__', _user['recipient'])
|
||||
if 'boat' in _user and _user['boat']:
|
||||
pushover_message = pushover_message.replace('__BOAT__', _user['boat'])
|
||||
if 'badge' in _user and _user['badge']:
|
||||
pushover_message = pushover_message.replace('__BADGE_NAME__', _user['badge'])
|
||||
if 'alert' in _user and _user['alert']:
|
||||
pushover_message = pushover_message.replace('__ALERT__', _user['alert'])
|
||||
|
||||
if 'app.url' in app and app['app.url']:
|
||||
pushover_message = pushover_message.replace('__APP_URL__', app['app.url'])
|
||||
|
||||
pushover_token = None
|
||||
if 'app.pushover_app_token' in app and app['app.pushover_app_token']:
|
||||
pushover_token = app['app.pushover_app_token']
|
||||
else:
|
||||
plpy.error('Error no pushover token defined, check app settings')
|
||||
return None
|
||||
pushover_user = None
|
||||
if 'pushover_user_key' in _user and _user['pushover_user_key']:
|
||||
pushover_user = _user['pushover_user_key']
|
||||
else:
|
||||
plpy.error('Error no pushover user token defined, check user settings')
|
||||
return None
|
||||
|
||||
# requests
|
||||
r = requests.post("https://api.pushover.net/1/messages.json", data = {
|
||||
"token": pushover_token,
|
||||
"user": pushover_user,
|
||||
"title": pushover_title,
|
||||
"message": pushover_message
|
||||
})
|
||||
|
||||
#print(r.text)
|
||||
# Return ?? or None if not found
|
||||
#plpy.notice('Sent pushover successfully to [{}] [{}]'.format(r.text, r.status_code))
|
||||
if r.status_code == 200:
|
||||
plpy.notice('Sent pushover successfully to [{}] [{}] [{}]'.format(pushover_user, pushover_title, r.text))
|
||||
else:
|
||||
plpy.error('Failed to send pushover')
|
||||
return None
|
||||
$send_pushover_py$ TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.send_pushover_py_fn
|
||||
IS 'Send pushover notification using plpython3u';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- python send telegram message
|
||||
-- https://core.telegram.org/
|
||||
DROP FUNCTION IF EXISTS send_telegram_py_fn;
|
||||
CREATE OR REPLACE FUNCTION send_telegram_py_fn(IN message_type TEXT, IN _user JSONB, IN app JSONB) RETURNS void
|
||||
AS $send_telegram_py$
|
||||
"""
|
||||
Send a message to a telegram user or group specified on chatId
|
||||
chat_id must be a number!
|
||||
"""
|
||||
import requests
|
||||
import json
|
||||
|
||||
# Use the shared cache to avoid preparing the email metadata
|
||||
if message_type in SD:
|
||||
plan = SD[message_type]
|
||||
# A prepared statement from Python
|
||||
else:
|
||||
plan = plpy.prepare("SELECT * FROM email_templates WHERE name = $1", ["text"])
|
||||
SD[message_type] = plan
|
||||
|
||||
# Execute the statement with the message_type param and limit to 1 result
|
||||
rv = plpy.execute(plan, [message_type], 1)
|
||||
telegram_title = rv[0]['pushover_title']
|
||||
telegram_message = rv[0]['pushover_message']
|
||||
|
||||
# Replace fields using input jsonb obj
|
||||
if 'logbook_name' in _user and _user['logbook_name']:
|
||||
telegram_message = telegram_message.replace('__LOGBOOK_NAME__', _user['logbook_name'])
|
||||
if 'logbook_link' in _user and _user['logbook_link']:
|
||||
telegram_message = telegram_message.replace('__LOGBOOK_LINK__', str(_user['logbook_link']))
|
||||
if 'recipient' in _user and _user['recipient']:
|
||||
telegram_message = telegram_message.replace('__RECIPIENT__', _user['recipient'])
|
||||
if 'boat' in _user and _user['boat']:
|
||||
telegram_message = telegram_message.replace('__BOAT__', _user['boat'])
|
||||
if 'badge' in _user and _user['badge']:
|
||||
telegram_message = telegram_message.replace('__BADGE_NAME__', _user['badge'])
|
||||
if 'alert' in _user and _user['alert']:
|
||||
telegram_message = telegram_message.replace('__ALERT__', _user['alert'])
|
||||
|
||||
if 'app.url' in app and app['app.url']:
|
||||
telegram_message = telegram_message.replace('__APP_URL__', app['app.url'])
|
||||
|
||||
telegram_token = None
|
||||
if 'app.telegram_bot_token' in app and app['app.telegram_bot_token']:
|
||||
telegram_token = app['app.telegram_bot_token']
|
||||
else:
|
||||
plpy.error('Error no telegram token defined, check app settings')
|
||||
return None
|
||||
telegram_chat_id = None
|
||||
if 'telegram_chat_id' in _user and _user['telegram_chat_id']:
|
||||
telegram_chat_id = _user['telegram_chat_id']
|
||||
else:
|
||||
plpy.error('Error no telegram user token defined, check user settings')
|
||||
return None
|
||||
|
||||
# requests
|
||||
headers = {'Content-Type': 'application/json',
|
||||
'Proxy-Authorization': 'Basic base64'}
|
||||
data_dict = {'chat_id': telegram_chat_id,
|
||||
'text': telegram_message,
|
||||
'parse_mode': 'HTML',
|
||||
'disable_notification': False}
|
||||
data = json.dumps(data_dict)
|
||||
url = f'https://api.telegram.org/bot{telegram_token}/sendMessage'
|
||||
r = requests.post(url,
|
||||
data=data,
|
||||
headers=headers)
|
||||
#print(r.text)
|
||||
# Return something boolean?
|
||||
#plpy.notice('Sent telegram successfully to [{}] [{}]'.format(r.text, r.status_code))
|
||||
if r.status_code == 200:
|
||||
plpy.notice('Sent telegram successfully to [{}] [{}] [{}]'.format(telegram_chat_id, telegram_title, r.text))
|
||||
else:
|
||||
plpy.error('Failed to send telegram')
|
||||
return None
|
||||
$send_telegram_py$ TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.send_telegram_py_fn
|
||||
IS 'Send a message to a telegram user or group specified on chatId using plpython3u';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- python url encode
|
||||
CREATE OR REPLACE FUNCTION urlencode_py_fn(uri text) RETURNS text
|
||||
AS $urlencode_py$
|
||||
import urllib.parse
|
||||
return urllib.parse.quote(uri, safe="");
|
||||
$urlencode_py$ LANGUAGE plpython3u IMMUTABLE STRICT;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.urlencode_py_fn
|
||||
IS 'python url encode using plpython3u';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- python
|
||||
-- https://ipapi.co/
|
||||
DROP FUNCTION IF EXISTS reverse_geoip_py_fn;
|
||||
CREATE OR REPLACE FUNCTION reverse_geoip_py_fn(IN _ip TEXT) RETURNS JSONB
|
||||
AS $reverse_geoip_py$
|
||||
"""
|
||||
Return ipapi.co ip details
|
||||
"""
|
||||
import requests
|
||||
import json
|
||||
|
||||
# requests
|
||||
url = f'https://ipapi.co/{_ip}/json/'
|
||||
r = requests.get(url)
|
||||
#print(r.text)
|
||||
#plpy.notice('IP [{}] [{}]'.format(_ip, r.status_code))
|
||||
if r.status_code == 200:
|
||||
#plpy.notice('Got [{}] [{}]'.format(r.text, r.status_code))
|
||||
return r.json()
|
||||
else:
|
||||
plpy.error('Failed to get ip details')
|
||||
return {}
|
||||
$reverse_geoip_py$ IMMUTABLE strict TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.reverse_geoip_py_fn
|
||||
IS 'Retrieve reverse geo IP location via ipapi.co using plpython3u';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- python url escape
|
||||
--
|
||||
DROP FUNCTION IF EXISTS urlescape_py_fn;
|
||||
CREATE OR REPLACE FUNCTION urlescape_py_fn(original text) RETURNS text LANGUAGE plpython3u AS $$
|
||||
import urllib.parse
|
||||
return urllib.parse.quote(original);
|
||||
$$
|
||||
IMMUTABLE STRICT;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.urlescape_py_fn
|
||||
IS 'URL-encoding VARCHAR and TEXT values using plpython3u';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- python geojson parser
|
||||
--
|
||||
--CREATE TYPE geometry_type AS ENUM ('LineString', 'Point');
|
||||
DROP FUNCTION IF EXISTS geojson_py_fn;
|
||||
CREATE OR REPLACE FUNCTION geojson_py_fn(IN original JSONB, IN geometry_type TEXT) RETURNS JSONB LANGUAGE plpython3u
|
||||
AS $geojson_py$
|
||||
import json
|
||||
parsed = json.loads(original)
|
||||
output = []
|
||||
#plpy.notice(parsed)
|
||||
# [None, None]
|
||||
if None not in parsed:
|
||||
for idx, x in enumerate(parsed):
|
||||
#plpy.notice(idx, x)
|
||||
for feature in x:
|
||||
#plpy.notice(feature)
|
||||
if (feature['geometry']['type'] != geometry_type):
|
||||
output.append(feature)
|
||||
#elif (feature['properties']['id']): TODO
|
||||
# output.append(feature)
|
||||
#else:
|
||||
# plpy.notice('ignoring')
|
||||
return json.dumps(output)
|
||||
$geojson_py$ -- TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
||||
IMMUTABLE STRICT;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.geojson_py_fn
|
||||
IS 'Parse geojson using plpython3u (should be done in PGSQL), deprecated';
|
||||
|
||||
DROP FUNCTION IF EXISTS overpass_py_fn;
|
||||
CREATE OR REPLACE FUNCTION overpass_py_fn(IN lon NUMERIC, IN lat NUMERIC,
|
||||
OUT geo JSONB) RETURNS JSONB
|
||||
AS $overpass_py$
|
||||
"""
|
||||
Return https://overpass-turbo.eu seamark details within 400m
|
||||
https://overpass-turbo.eu/s/1EaG
|
||||
https://wiki.openstreetmap.org/wiki/Key:seamark:type
|
||||
"""
|
||||
import requests
|
||||
import json
|
||||
import urllib.parse
|
||||
|
||||
headers = {'User-Agent': 'PostgSail', 'From': 'xbgmsharp@gmail.com'}
|
||||
payload = """
|
||||
[out:json][timeout:20];
|
||||
is_in({0},{1})->.result_areas;
|
||||
(
|
||||
area.result_areas["seamark:type"~"(mooring|harbour)"][~"^seamark:.*:category$"~"."];
|
||||
area.result_areas["leisure"="marina"][~"name"~"."];
|
||||
);
|
||||
out tags;
|
||||
nwr(around:400.0,{0},{1})->.all;
|
||||
(
|
||||
nwr.all["seamark:type"~"(mooring|harbour)"][~"^seamark:.*:category$"~"."];
|
||||
nwr.all["seamark:type"~"(anchorage|anchor_berth|berth)"];
|
||||
nwr.all["leisure"="marina"];
|
||||
nwr.all["natural"~"(bay|beach)"];
|
||||
);
|
||||
out tags;
|
||||
""".format(lat, lon)
|
||||
data = urllib.parse.quote(payload, safe="");
|
||||
url = f'https://overpass-api.de/api/interpreter?data={data}'.format(data)
|
||||
r = requests.get(url, headers)
|
||||
#print(r.text)
|
||||
#plpy.notice(url)
|
||||
plpy.notice('overpass-api coord lon[{}] lat[{}] [{}]'.format(lon, lat, r.status_code))
|
||||
if r.status_code == 200 and "elements" in r.json():
|
||||
r_dict = r.json()
|
||||
plpy.notice('overpass-api Got [{}]'.format(r_dict["elements"]))
|
||||
if r_dict["elements"]:
|
||||
if "tags" in r_dict["elements"][0] and r_dict["elements"][0]["tags"]:
|
||||
return r_dict["elements"][0]["tags"]; # return the first element
|
||||
return {}
|
||||
else:
|
||||
plpy.notice('overpass-api Failed to get overpass-api details')
|
||||
return {}
|
||||
$overpass_py$ IMMUTABLE strict TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.overpass_py_fn
|
||||
IS 'Return https://overpass-turbo.eu seamark details within 400m using plpython3u';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Provision Grafana SQL
|
||||
--
|
||||
CREATE OR REPLACE FUNCTION grafana_py_fn(IN _v_name TEXT, IN _v_id TEXT,
|
||||
IN _u_email TEXT, IN app JSONB) RETURNS VOID
|
||||
AS $grafana_py$
|
||||
"""
|
||||
https://grafana.com/docs/grafana/latest/developers/http_api/
|
||||
Create organization base on vessel name
|
||||
Create user base on user email
|
||||
Add user to organization
|
||||
Add data_source to organization
|
||||
Add dashboard to organization
|
||||
Update organization preferences
|
||||
"""
|
||||
import requests
|
||||
import json
|
||||
import re
|
||||
|
||||
grafana_uri = None
|
||||
if 'app.grafana_admin_uri' in app and app['app.grafana_admin_uri']:
|
||||
grafana_uri = app['app.grafana_admin_uri']
|
||||
else:
|
||||
plpy.error('Error no grafana_admin_uri defined, check app settings')
|
||||
return None
|
||||
|
||||
b_name = None
|
||||
if not _v_name:
|
||||
b_name = _v_id
|
||||
else:
|
||||
b_name = _v_name
|
||||
|
||||
# add vessel org
|
||||
headers = {'User-Agent': 'PostgSail', 'From': 'xbgmsharp@gmail.com',
|
||||
'Accept': 'application/json', 'Content-Type': 'application/json'}
|
||||
path = 'api/orgs'
|
||||
url = f'{grafana_uri}/{path}'.format(grafana_uri,path)
|
||||
data_dict = {'name':b_name}
|
||||
data = json.dumps(data_dict)
|
||||
r = requests.post(url, data=data, headers=headers)
|
||||
#print(r.text)
|
||||
#plpy.notice(r.json())
|
||||
if r.status_code == 200 and "orgId" in r.json():
|
||||
org_id = r.json()['orgId']
|
||||
else:
|
||||
plpy.error('Error grafana add vessel org %', r.json())
|
||||
return None
|
||||
|
||||
# add user to vessel org
|
||||
path = 'api/admin/users'
|
||||
url = f'{grafana_uri}/{path}'.format(grafana_uri,path)
|
||||
data_dict = {'orgId':org_id, 'email':_u_email, 'password':'asupersecretpassword'}
|
||||
data = json.dumps(data_dict)
|
||||
r = requests.post(url, data=data, headers=headers)
|
||||
#print(r.text)
|
||||
#plpy.notice(r.json())
|
||||
if r.status_code == 200 and "id" in r.json():
|
||||
user_id = r.json()['id']
|
||||
else:
|
||||
plpy.error('Error grafana add user to vessel org')
|
||||
return
|
||||
|
||||
# read data_source
|
||||
path = 'api/datasources/1'
|
||||
url = f'{grafana_uri}/{path}'.format(grafana_uri,path)
|
||||
r = requests.get(url, headers=headers)
|
||||
#print(r.text)
|
||||
#plpy.notice(r.json())
|
||||
data_source = r.json()
|
||||
data_source['id'] = 0
|
||||
data_source['orgId'] = org_id
|
||||
data_source['uid'] = "ds_" + _v_id
|
||||
data_source['name'] = "ds_" + _v_id
|
||||
data_source['secureJsonData'] = {}
|
||||
data_source['secureJsonData']['password'] = 'password'
|
||||
data_source['readOnly'] = True
|
||||
del data_source['secureJsonFields']
|
||||
|
||||
# add data_source to vessel org
|
||||
path = 'api/datasources'
|
||||
url = f'{grafana_uri}/{path}'.format(grafana_uri,path)
|
||||
data = json.dumps(data_source)
|
||||
headers['X-Grafana-Org-Id'] = str(org_id)
|
||||
r = requests.post(url, data=data, headers=headers)
|
||||
#plpy.notice(r.json())
|
||||
del headers['X-Grafana-Org-Id']
|
||||
if r.status_code != 200 and "id" not in r.json():
|
||||
plpy.error('Error grafana add data_source to vessel org')
|
||||
return
|
||||
|
||||
dashboards_tpl = [ 'pgsail_tpl_electrical', 'pgsail_tpl_logbook', 'pgsail_tpl_monitor', 'pgsail_tpl_rpi', 'pgsail_tpl_solar', 'pgsail_tpl_weather', 'pgsail_tpl_home']
|
||||
for dashboard in dashboards_tpl:
|
||||
# read dashboard template by uid
|
||||
path = 'api/dashboards/uid'
|
||||
url = f'{grafana_uri}/{path}/{dashboard}'.format(grafana_uri,path,dashboard)
|
||||
if 'X-Grafana-Org-Id' in headers:
|
||||
del headers['X-Grafana-Org-Id']
|
||||
r = requests.get(url, headers=headers)
|
||||
#plpy.notice(r.json())
|
||||
if r.status_code != 200 and "id" not in r.json():
|
||||
plpy.error('Error grafana read dashboard template')
|
||||
return
|
||||
new_dashboard = r.json()
|
||||
del new_dashboard['meta']
|
||||
new_dashboard['dashboard']['version'] = 0
|
||||
new_dashboard['dashboard']['id'] = 0
|
||||
new_uid = re.sub(r'pgsail_tpl_(.*)', r'postgsail_\1', new_dashboard['dashboard']['uid'])
|
||||
new_dashboard['dashboard']['uid'] = f'{new_uid}_{_v_id}'.format(new_uid,_v_id)
|
||||
# add dashboard to vessel org
|
||||
path = 'api/dashboards/db'
|
||||
url = f'{grafana_uri}/{path}'.format(grafana_uri,path)
|
||||
data = json.dumps(new_dashboard)
|
||||
new_data = data.replace('PCC52D03280B7034C', data_source['uid'])
|
||||
headers['X-Grafana-Org-Id'] = str(org_id)
|
||||
r = requests.post(url, data=new_data, headers=headers)
|
||||
#plpy.notice(r.json())
|
||||
if r.status_code != 200 and "id" not in r.json():
|
||||
plpy.error('Error grafana add dashboard to vessel org')
|
||||
return
|
||||
|
||||
# Update Org Prefs
|
||||
path = 'api/org/preferences'
|
||||
url = f'{grafana_uri}/{path}'.format(grafana_uri,path)
|
||||
home_dashboard = {}
|
||||
home_dashboard['timezone'] = 'utc'
|
||||
home_dashboard['homeDashboardUID'] = f'postgsail_home_{_v_id}'.format(_v_id)
|
||||
data = json.dumps(home_dashboard)
|
||||
headers['X-Grafana-Org-Id'] = str(org_id)
|
||||
r = requests.patch(url, data=data, headers=headers)
|
||||
#plpy.notice(r.json())
|
||||
if r.status_code != 200:
|
||||
plpy.error('Error grafana update org preferences')
|
||||
return
|
||||
|
||||
plpy.notice('Done')
|
||||
$grafana_py$ TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.grafana_py_fn
|
||||
IS 'Grafana Organization,User,data_source,dashboards provisioning via HTTP API using plpython3u';
|
||||
|
||||
-- https://stackoverflow.com/questions/65517230/how-to-set-user-attribute-value-in-keycloak-using-api
|
||||
DROP FUNCTION IF EXISTS keycloak_py_fn;
|
||||
CREATE OR REPLACE FUNCTION keycloak_py_fn(IN user_id TEXT, IN vessel_id TEXT,
|
||||
IN app JSONB) RETURNS JSONB
|
||||
AS $keycloak_py$
|
||||
"""
|
||||
Add vessel_id user attribute to keycloak user {user_id}
|
||||
"""
|
||||
import requests
|
||||
import json
|
||||
import urllib.parse
|
||||
|
||||
safe_uri = host = user = pwd = None
|
||||
if 'app.keycloak_uri' in app and app['app.keycloak_uri']:
|
||||
#safe_uri = urllib.parse.quote(app['app.keycloak_uri'], safe=':/?&=')
|
||||
_ = urllib.parse.urlparse(app['app.keycloak_uri'])
|
||||
host = _.netloc.split('@')[-1]
|
||||
user = _.netloc.split(':')[0]
|
||||
pwd = _.netloc.split(':')[1].split('@')[0]
|
||||
else:
|
||||
plpy.error('Error no keycloak_uri defined, check app settings')
|
||||
return None
|
||||
|
||||
if not host or not user or not pwd:
|
||||
plpy.error('Error parsing keycloak_uri, check app settings')
|
||||
return None
|
||||
|
||||
_headers = {'User-Agent': 'PostgSail', 'From': 'xbgmsharp@gmail.com'}
|
||||
_payload = {'client_id':'admin-cli','grant_type':'password','username':user,'password':pwd}
|
||||
url = f'{_.scheme}://{host}/realms/master/protocol/openid-connect/token'.format(_.scheme, host)
|
||||
r = requests.post(url, headers=_headers, data=_payload, timeout=(5, 60))
|
||||
#print(r.text)
|
||||
#plpy.notice(url)
|
||||
if r.status_code == 200 and 'access_token' in r.json():
|
||||
response = r.json()
|
||||
plpy.notice(response)
|
||||
_headers['Authorization'] = 'Bearer '+ response['access_token']
|
||||
_headers['Content-Type'] = 'application/json'
|
||||
_payload = { 'attributes': {'vessel_id': vessel_id} }
|
||||
url = f'{keycloak_uri}/admin/realms/postgsail/users/{user_id}'.format(keycloak_uri,user_id)
|
||||
#plpy.notice(url)
|
||||
#plpy.notice(_payload)
|
||||
data = json.dumps(_payload)
|
||||
r = requests.put(url, headers=_headers, data=data, timeout=(5, 60))
|
||||
if r.status_code != 204:
|
||||
plpy.notice("Error updating user: {status} [{text}]".format(
|
||||
status=r.status_code, text=r.text))
|
||||
return None
|
||||
else:
|
||||
plpy.notice("Updated user : {user} [{text}]".format(user=user_id, text=r.text))
|
||||
else:
|
||||
plpy.notice(f'Error getting admin access_token: {status} [{text}]'.format(
|
||||
status=r.status_code, text=r.text))
|
||||
return None
|
||||
$keycloak_py$ strict TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.keycloak_py_fn
|
||||
IS 'Set oauth user attribute into keycloak using plpython3u';
|
||||
|
||||
DROP FUNCTION IF EXISTS keycloak_auth_py_fn;
|
||||
CREATE OR REPLACE FUNCTION keycloak_auth_py_fn(IN _v_id TEXT,
|
||||
IN _user JSONB, IN app JSONB) RETURNS JSONB
|
||||
AS $keycloak_auth_py$
|
||||
"""
|
||||
Add keycloak user
|
||||
"""
|
||||
import requests
|
||||
import json
|
||||
import urllib.parse
|
||||
|
||||
safe_uri = host = user = pwd = None
|
||||
if 'app.keycloak_uri' in app and app['app.keycloak_uri']:
|
||||
#safe_uri = urllib.parse.quote(app['app.keycloak_uri'], safe=':/?&=')
|
||||
_ = urllib.parse.urlparse(app['app.keycloak_uri'])
|
||||
host = _.netloc.split('@')[-1]
|
||||
user = _.netloc.split(':')[0]
|
||||
pwd = _.netloc.split(':')[1].split('@')[0]
|
||||
else:
|
||||
plpy.error('Error no keycloak_uri defined, check app settings')
|
||||
return none
|
||||
|
||||
if not host or not user or not pwd:
|
||||
plpy.error('Error parsing keycloak_uri, check app settings')
|
||||
return None
|
||||
|
||||
if not 'email' in _user and _user['email']:
|
||||
plpy.error('Error parsing user email, check user settings')
|
||||
return none
|
||||
|
||||
if not _v_id:
|
||||
plpy.error('Error parsing vessel_id')
|
||||
return none
|
||||
|
||||
_headers = {'User-Agent': 'PostgSail', 'From': 'xbgmsharp@gmail.com'}
|
||||
_payload = {'client_id':'admin-cli','grant_type':'password','username':user,'password':pwd}
|
||||
url = f'{_.scheme}://{host}/realms/master/protocol/openid-connect/token'.format(_.scheme, host)
|
||||
r = requests.post(url, headers=_headers, data=_payload, timeout=(5, 60))
|
||||
#print(r.text)
|
||||
#plpy.notice(url)
|
||||
if r.status_code == 200 and 'access_token' in r.json():
|
||||
response = r.json()
|
||||
#plpy.notice(response)
|
||||
_headers['Authorization'] = 'Bearer '+ response['access_token']
|
||||
_headers['Content-Type'] = 'application/json'
|
||||
url = f'{_.scheme}://{host}/admin/realms/postgsail/users'.format(_.scheme, host)
|
||||
_payload = {
|
||||
"enabled": "true",
|
||||
"email": _user['email'],
|
||||
"firstName": _user['recipient'],
|
||||
"attributes": {"vessel_id": _v_id},
|
||||
"emailVerified": True,
|
||||
"requiredActions":["UPDATE_PROFILE", "UPDATE_PASSWORD"]
|
||||
}
|
||||
#plpy.notice(_payload)
|
||||
data = json.dumps(_payload)
|
||||
r = requests.post(url, headers=_headers, data=data, timeout=(5, 60))
|
||||
if r.status_code != 201:
|
||||
#print("Error creating user: {status}".format(status=r.status_code))
|
||||
plpy.error(f'Error creating user: {user} {status}'.format(user=_payload['email'], status=r.status_code))
|
||||
return None
|
||||
else:
|
||||
#print("Created user : {u}]".format(u=_payload['email']))
|
||||
plpy.notice('Created user : {u} {t}, {l}'.format(u=_payload['email'], t=r.text, l=r.headers['location']))
|
||||
user_url = "{user_url}/execute-actions-email".format(user_url=r.headers['location'])
|
||||
_payload = ["UPDATE_PASSWORD"]
|
||||
#plpy.notice(_payload)
|
||||
data = json.dumps(_payload)
|
||||
r = requests.put(user_url, headers=_headers, data=data, timeout=(5, 60))
|
||||
if r.status_code != 204:
|
||||
plpy.error('Error execute-actions-email: {u} {s}'.format(u=_user['email'], s=r.status_code))
|
||||
else:
|
||||
plpy.notice('execute-actions-email: {u} {s}'.format(u=_user['email'], s=r.status_code))
|
||||
return None
|
||||
else:
|
||||
plpy.error(f'Error getting admin access_token: {status}'.format(status=r.status_code))
|
||||
return None
|
||||
$keycloak_auth_py$ strict TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.keycloak_auth_py_fn
|
||||
IS 'Create an oauth user into keycloak using plpython3u';
|
||||
|
||||
CREATE OR REPLACE FUNCTION windy_pws_py_fn(IN metric JSONB,
|
||||
IN _user JSONB, IN app JSONB) RETURNS JSONB
|
||||
AS $windy_pws_py$
|
||||
"""
|
||||
Send environment data from boat instruments to Windy as a Personal Weather Station (PWS)
|
||||
https://community.windy.com/topic/8168/report-your-weather-station-data-to-windy
|
||||
"""
|
||||
import requests
|
||||
import json
|
||||
import decimal
|
||||
|
||||
if not 'app.windy_apikey' in app and not app['app.windy_apikey']:
|
||||
plpy.error('Error no windy_apikey defined, check app settings')
|
||||
return none
|
||||
if not 'station' in metric and not metric['station']:
|
||||
plpy.error('Error no metrics defined')
|
||||
return none
|
||||
if not 'temp' in metric and not metric['temp']:
|
||||
plpy.error('Error no metrics defined')
|
||||
return none
|
||||
if not _user:
|
||||
plpy.error('Error no user defined, check user settings')
|
||||
return none
|
||||
|
||||
_headers = {'User-Agent': 'PostgSail', 'From': 'xbgmsharp@gmail.com', 'Content-Type': 'application/json'}
|
||||
_payload = {
|
||||
'stations': [
|
||||
{ 'station': int(decimal.Decimal(metric['station'])),
|
||||
'name': metric['name'],
|
||||
'shareOption': 'Open',
|
||||
'type': 'SignalK PostgSail Plugin',
|
||||
'provider': 'PostgSail',
|
||||
'url': 'https://iot.openplotter.cloud/{name}/monitoring'.format(name=metric['name']),
|
||||
'lat': float(decimal.Decimal(metric['lat'])),
|
||||
'lon': float(decimal.Decimal(metric['lon'])),
|
||||
'elevation': 1 }
|
||||
],
|
||||
'observations': [
|
||||
{ 'station': int(decimal.Decimal(metric['station'])),
|
||||
'temp': float(decimal.Decimal(metric['temp'])),
|
||||
'wind': round(float(decimal.Decimal(metric['wind']))),
|
||||
'gust': round(float(decimal.Decimal(metric['wind']))),
|
||||
'winddir': int(decimal.Decimal(metric['winddir'])),
|
||||
'pressure': int(decimal.Decimal(metric['pressure'])),
|
||||
'rh': float(decimal.Decimal(metric['rh'])) }
|
||||
]}
|
||||
#print(_payload)
|
||||
#plpy.notice(_payload)
|
||||
data = json.dumps(_payload)
|
||||
api_url = 'https://stations.windy.com/pws/update/{api_key}'.format(api_key=app['app.windy_apikey'])
|
||||
r = requests.post(api_url, data=data, headers=_headers, timeout=(5, 60))
|
||||
#print(r.text)
|
||||
#plpy.notice(api_url)
|
||||
if r.status_code == 200:
|
||||
#print('Data sent successfully!')
|
||||
plpy.notice('Data sent successfully to Windy!')
|
||||
#plpy.notice(api_url)
|
||||
if not 'windy' in _user['settings']:
|
||||
api_url = 'https://stations.windy.com/pws/station/{api_key}/{station}'.format(api_key=app['app.windy_apikey'], station=metric['station'])
|
||||
#print(r.text)
|
||||
#plpy.notice(api_url)
|
||||
r = requests.get(api_url, timeout=(5, 60))
|
||||
if r.status_code == 200:
|
||||
#print('Windy Personal Weather Station created successfully in Windy Stations!')
|
||||
plpy.notice('Windy Personal Weather Station created successfully in Windy Stations!')
|
||||
return r.json()
|
||||
else:
|
||||
plpy.error(f'Failed to gather PWS details. Status code: {r.status_code}')
|
||||
else:
|
||||
plpy.error(f'Failed to send data. Status code: {r.status_code}')
|
||||
#print(f'Failed to send data. Status code: {r.status_code}')
|
||||
#print(r.text)
|
||||
return {}
|
||||
$windy_pws_py$ strict TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.windy_pws_py_fn
|
||||
IS 'Forward vessel data to Windy as a Personal Weather Station using plpython3u';
|
431
initdb/02_4_signalk_auth.sql
Normal file
431
initdb/02_4_signalk_auth.sql
Normal file
@@ -0,0 +1,431 @@
|
||||
---------------------------------------------------------------------------
|
||||
-- SQL User Management - Storing Users and Passwords and Vessels
|
||||
-- We put things inside the auth schema to hide
|
||||
-- them from public view. Certain public procs/views will
|
||||
-- refer to helpers and tables inside.
|
||||
-- base on https://postgrest.org/en/stable/auth.html#sql-user-management
|
||||
|
||||
-- List current database
|
||||
select current_database();
|
||||
|
||||
-- connect to the DB
|
||||
\c signalk
|
||||
|
||||
CREATE SCHEMA IF NOT EXISTS auth;
|
||||
COMMENT ON SCHEMA auth IS 'auth postgrest for users and vessels';
|
||||
|
||||
CREATE EXTENSION IF NOT EXISTS "uuid-ossp"; -- provides functions to generate universally unique identifiers (UUIDs)
|
||||
CREATE EXTENSION IF NOT EXISTS "moddatetime"; -- provides functions for tracking last modification time
|
||||
CREATE EXTENSION IF NOT EXISTS "citext"; -- provides data type for case-insensitive character strings
|
||||
CREATE EXTENSION IF NOT EXISTS "pgcrypto"; -- provides cryptographic functions
|
||||
|
||||
DROP TABLE IF EXISTS auth.accounts CASCADE;
|
||||
CREATE TABLE IF NOT EXISTS auth.accounts (
|
||||
id INT UNIQUE GENERATED ALWAYS AS IDENTITY,
|
||||
--id TEXT NOT NULL UNIQUE DEFAULT uuid_generate_v7(),
|
||||
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),
|
||||
last TEXT NOT NULL CHECK (length(pass) < 512),
|
||||
pass TEXT NOT NULL CHECK (length(pass) < 512),
|
||||
role name NOT NULL CHECK (length(role) < 512),
|
||||
preferences JSONB NULL DEFAULT '{"email_notifications":true}',
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
connected_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
CONSTRAINT valid_email CHECK (length(email) > 5), -- Enforce at least 5 char, eg: a@b.io
|
||||
CONSTRAINT valid_first CHECK (length(first) > 1),
|
||||
CONSTRAINT valid_last CHECK (length(last) > 1),
|
||||
CONSTRAINT valid_pass CHECK (length(pass) > 4)
|
||||
);
|
||||
-- Description
|
||||
COMMENT ON TABLE
|
||||
auth.accounts
|
||||
IS 'users account table';
|
||||
-- Indexes
|
||||
CREATE INDEX accounts_preferences_idx ON auth.accounts USING GIN (preferences);
|
||||
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';
|
||||
|
||||
CREATE TRIGGER accounts_moddatetime
|
||||
BEFORE UPDATE ON auth.accounts
|
||||
FOR EACH ROW
|
||||
EXECUTE PROCEDURE moddatetime (updated_at);
|
||||
-- Description
|
||||
COMMENT ON TRIGGER accounts_moddatetime
|
||||
ON auth.accounts
|
||||
IS 'Automatic update of updated_at on table modification';
|
||||
|
||||
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),
|
||||
-- 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 NUMERIC UNIQUE, -- MMSI can be optional but if present must be a valid one and unique
|
||||
name TEXT NOT NULL CHECK (length(name) >= 3 AND length(name) < 512),
|
||||
role name not null check (length(role) < 512),
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
CONSTRAINT valid_range_mmsi CHECK (mmsi > 100000000 AND mmsi < 800000000)
|
||||
);
|
||||
-- Description
|
||||
COMMENT ON TABLE
|
||||
auth.vessels
|
||||
IS 'vessels table link to accounts email user_id column';
|
||||
COMMENT ON COLUMN
|
||||
auth.vessels.mmsi
|
||||
IS 'MMSI can be optional but if present must be a valid one and unique but must be in numeric range between 100000000 and 800000000';
|
||||
|
||||
CREATE TRIGGER vessels_moddatetime
|
||||
BEFORE UPDATE ON auth.vessels
|
||||
FOR EACH ROW
|
||||
EXECUTE PROCEDURE moddatetime (updated_at);
|
||||
-- Description
|
||||
COMMENT ON TRIGGER vessels_moddatetime
|
||||
ON auth.vessels
|
||||
IS 'Automatic update of updated_at on table modification';
|
||||
|
||||
CREATE TABLE auth.users (
|
||||
id NAME PRIMARY KEY DEFAULT current_setting('request.jwt.claims', true)::json->>'sub',
|
||||
email NAME NOT NULL DEFAULT current_setting('request.jwt.claims', true)::json->>'email',
|
||||
user_id TEXT NOT NULL UNIQUE DEFAULT RIGHT(gen_random_uuid()::text, 12),
|
||||
first TEXT NOT NULL DEFAULT current_setting('request.jwt.claims', true)::json->>'given_name',
|
||||
last TEXT NOT NULL DEFAULT current_setting('request.jwt.claims', true)::json->>'family_name',
|
||||
role NAME NOT NULL DEFAULT 'user_role' CHECK (length(role) < 512),
|
||||
preferences JSONB NULL DEFAULT '{"email_notifications":true, "email_valid": true, "email_verified": true}',
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
connected_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
-- Description
|
||||
COMMENT ON TABLE
|
||||
auth.users
|
||||
IS 'Keycloak Oauth user, map user details from access token';
|
||||
|
||||
CREATE TRIGGER user_moddatetime
|
||||
BEFORE UPDATE ON auth.users
|
||||
FOR EACH ROW
|
||||
EXECUTE PROCEDURE moddatetime (updated_at);
|
||||
-- Description
|
||||
COMMENT ON TRIGGER user_moddatetime
|
||||
ON auth.users
|
||||
IS 'Automatic update of updated_at on table modification';
|
||||
|
||||
create or replace function
|
||||
auth.check_role_exists() returns trigger as $$
|
||||
begin
|
||||
if not exists (select 1 from pg_roles as r where r.rolname = new.role) then
|
||||
raise foreign_key_violation using message =
|
||||
'unknown database role: ' || new.role;
|
||||
return null;
|
||||
end if;
|
||||
return new;
|
||||
end
|
||||
$$ language plpgsql;
|
||||
|
||||
-- trigger check role on account
|
||||
drop trigger if exists ensure_user_role_exists on auth.accounts;
|
||||
create constraint trigger ensure_user_role_exists
|
||||
after insert or update on auth.accounts
|
||||
for each row
|
||||
execute procedure auth.check_role_exists();
|
||||
-- Description
|
||||
COMMENT ON TRIGGER ensure_user_role_exists
|
||||
ON auth.accounts
|
||||
IS 'ensure user role exists';
|
||||
|
||||
-- trigger add queue new account
|
||||
CREATE TRIGGER new_account_entry AFTER INSERT ON auth.accounts
|
||||
FOR EACH ROW EXECUTE FUNCTION public.new_account_entry_fn();
|
||||
-- Description
|
||||
COMMENT ON TRIGGER new_account_entry
|
||||
ON auth.accounts
|
||||
IS 'Add new account in process_queue for further processing';
|
||||
|
||||
-- trigger add queue new account OTP validation
|
||||
CREATE TRIGGER new_account_otp_validation_entry AFTER INSERT ON auth.accounts
|
||||
FOR EACH ROW EXECUTE FUNCTION public.new_account_otp_validation_entry_fn();
|
||||
-- Description
|
||||
COMMENT ON TRIGGER new_account_otp_validation_entry
|
||||
ON auth.accounts
|
||||
IS 'Add new account OTP validation in process_queue for further processing';
|
||||
|
||||
-- trigger check role on vessel
|
||||
drop trigger if exists ensure_vessel_role_exists on auth.vessels;
|
||||
create constraint trigger ensure_vessel_role_exists
|
||||
after insert or update on auth.vessels
|
||||
for each row
|
||||
execute procedure auth.check_role_exists();
|
||||
-- trigger add queue new vessel
|
||||
CREATE TRIGGER new_vessel_entry AFTER INSERT ON auth.vessels
|
||||
FOR EACH ROW EXECUTE FUNCTION public.new_vessel_entry_fn();
|
||||
-- Description
|
||||
COMMENT ON TRIGGER new_vessel_entry
|
||||
ON auth.vessels
|
||||
IS 'Add new vessel in process_queue for further processing';
|
||||
|
||||
-- trigger add new vessel name as public_vessel user configuration
|
||||
CREATE TRIGGER new_vessel_public AFTER INSERT ON auth.vessels
|
||||
FOR EACH ROW EXECUTE FUNCTION public.new_vessel_public_fn();
|
||||
-- Description
|
||||
COMMENT ON TRIGGER new_vessel_public
|
||||
ON auth.vessels
|
||||
IS 'Add new vessel name as public_vessel user configuration';
|
||||
|
||||
create or replace function
|
||||
auth.encrypt_pass() returns trigger as $$
|
||||
begin
|
||||
if tg_op = 'INSERT' or new.pass <> old.pass then
|
||||
new.pass = crypt(new.pass, gen_salt('bf'));
|
||||
end if;
|
||||
return new;
|
||||
end
|
||||
$$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
auth.encrypt_pass
|
||||
IS 'encrypt user pass on insert or update';
|
||||
|
||||
drop trigger if exists encrypt_pass on auth.accounts;
|
||||
create trigger encrypt_pass
|
||||
before insert or update on auth.accounts
|
||||
for each row
|
||||
execute procedure auth.encrypt_pass();
|
||||
|
||||
create or replace function
|
||||
auth.user_role(email text, pass text) returns name
|
||||
language plpgsql
|
||||
as $$
|
||||
begin
|
||||
return (
|
||||
select role from auth.accounts
|
||||
where accounts.email = user_role.email
|
||||
and user_role.pass is NOT NULL
|
||||
and accounts.pass = crypt(user_role.pass, accounts.pass)
|
||||
);
|
||||
end;
|
||||
$$;
|
||||
|
||||
-- add type
|
||||
CREATE TYPE auth.jwt_token AS (
|
||||
token text
|
||||
);
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- API account helper functions
|
||||
--
|
||||
-- login should be on your exposed schema
|
||||
create or replace function
|
||||
api.login(in email text, in pass text) returns auth.jwt_token as $$
|
||||
declare
|
||||
_role name;
|
||||
result auth.jwt_token;
|
||||
app_jwt_secret text;
|
||||
_email_valid boolean := false;
|
||||
_email text := email;
|
||||
_user_id text := null;
|
||||
begin
|
||||
-- check email and password
|
||||
select auth.user_role(email, pass) into _role;
|
||||
if _role is null then
|
||||
-- HTTP/403
|
||||
--raise invalid_password using message = 'invalid user or password';
|
||||
-- HTTP/401
|
||||
raise insufficient_privilege using message = 'invalid user or password';
|
||||
end if;
|
||||
|
||||
-- Get app_jwt_secret
|
||||
SELECT value INTO app_jwt_secret
|
||||
FROM app_settings
|
||||
WHERE name = 'app.jwt_secret';
|
||||
|
||||
-- Check email_valid and generate OTP
|
||||
SELECT preferences['email_valid'],user_id INTO _email_valid,_user_id
|
||||
FROM auth.accounts a
|
||||
WHERE a.email = _email;
|
||||
IF _email_valid is null or _email_valid is False THEN
|
||||
INSERT INTO process_queue (channel, payload, stored, ref_id)
|
||||
VALUES ('email_otp', email, now(), _user_id);
|
||||
END IF;
|
||||
|
||||
--RAISE WARNING 'api.login debug: [%],[%],[%]', app_jwt_secret, _role, login.email;
|
||||
-- Generate jwt
|
||||
select jwt.sign(
|
||||
-- row_to_json(r), ''
|
||||
-- row_to_json(r)::json, current_setting('app.jwt_secret')::text
|
||||
row_to_json(r)::json, app_jwt_secret
|
||||
) as token
|
||||
from (
|
||||
select _role as role, login.email as email, -- TODO replace with user_id
|
||||
-- select _role as role, user_id as uid, -- add support in check_jwt
|
||||
extract(epoch from now())::integer + 60*60 as exp
|
||||
) r
|
||||
into result;
|
||||
return result;
|
||||
end;
|
||||
$$ language plpgsql security definer;
|
||||
|
||||
-- signup should be on your exposed schema
|
||||
create or replace function
|
||||
api.signup(in email text, in pass text, in firstname text, in lastname text) returns auth.jwt_token as $$
|
||||
declare
|
||||
_role name;
|
||||
begin
|
||||
IF email IS NULL OR email = ''
|
||||
OR pass IS NULL OR pass = '' THEN
|
||||
RAISE EXCEPTION 'Invalid input'
|
||||
USING HINT = 'Check your parameter';
|
||||
END IF;
|
||||
-- check email and password
|
||||
select auth.user_role(email, pass) into _role;
|
||||
if _role is null then
|
||||
RAISE WARNING 'Register new account email:[%]', email;
|
||||
-- TODO replace preferences default into table rather than trigger
|
||||
INSERT INTO auth.accounts ( email, pass, first, last, role, preferences)
|
||||
VALUES (email, pass, firstname, lastname, 'user_role', '{"email_notifications":true}');
|
||||
end if;
|
||||
return ( api.login(email, pass) );
|
||||
end;
|
||||
$$ language plpgsql security definer;
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- API account Oauth functions
|
||||
--
|
||||
-- oauth is on your exposed schema
|
||||
create or replace function
|
||||
api.oauth() returns void as $$
|
||||
declare
|
||||
_exist boolean;
|
||||
begin
|
||||
-- Ensure we have the required key/value in the access token
|
||||
if current_setting('request.jwt.claims', true)::json->>'sub' is null OR
|
||||
current_setting('request.jwt.claims', true)::json->>'email' is null THEN
|
||||
return;
|
||||
end if;
|
||||
-- check email exist
|
||||
select exists( select email from auth.users
|
||||
where id = current_setting('request.jwt.claims', true)::json->>'sub'
|
||||
) INTO _exist;
|
||||
if NOT FOUND then
|
||||
RAISE WARNING 'Register new oauth user email:[%]', current_setting('request.jwt.claims', true)::json->>'email';
|
||||
-- insert new user, default value from the oauth access token
|
||||
INSERT INTO auth.users (role, preferences)
|
||||
VALUES ('user_role', '{"email_notifications":true, "email_valid": true, "email_verified": true}');
|
||||
end if;
|
||||
end;
|
||||
$$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.oauth
|
||||
IS 'openid/oauth user register entry point';
|
||||
|
||||
create or replace function
|
||||
api.oauth_vessel(in _mmsi text, in _name text) returns void as $$
|
||||
declare
|
||||
_exist boolean;
|
||||
vessel_name text := _name;
|
||||
vessel_mmsi text := _mmsi;
|
||||
_vessel_id text := null;
|
||||
vessel_rec record;
|
||||
app_settings jsonb;
|
||||
_user_id text := null;
|
||||
begin
|
||||
RAISE WARNING 'oauth_vessel:[%]', current_setting('user.email', true);
|
||||
RAISE WARNING 'oauth_vessel:[%]', current_setting('request.jwt.claims', true)::json->>'email';
|
||||
-- Ensure we have the required key/value in the access token
|
||||
if current_setting('request.jwt.claims', true)::json->>'sub' is null OR
|
||||
current_setting('request.jwt.claims', true)::json->>'email' is null THEN
|
||||
return;
|
||||
end if;
|
||||
|
||||
-- check email exist
|
||||
select exists( select email from auth.accounts
|
||||
where email = current_setting('request.jwt.claims', true)::json->>'email'
|
||||
) INTO _exist;
|
||||
if _exist is False then
|
||||
RAISE WARNING 'Register new oauth user email:[%]', current_setting('request.jwt.claims', true)::json->>'email';
|
||||
-- insert new user, default value from the oauth access token
|
||||
INSERT INTO auth.users VALUES(DEFAULT) RETURNING user_id INTO _user_id;
|
||||
-- insert new user to account table from the oauth access token
|
||||
INSERT INTO auth.accounts (email, first, last, pass, user_id, role, preferences)
|
||||
VALUES (current_setting('request.jwt.claims', true)::json->>'email',
|
||||
current_setting('request.jwt.claims', true)::json->>'given_name',
|
||||
current_setting('request.jwt.claims', true)::json->>'family_name',
|
||||
current_setting('request.jwt.claims', true)::json->>'sub',
|
||||
_user_id, 'user_role', '{"email_notifications":true, "email_valid": true, "email_verified": true}');
|
||||
end if;
|
||||
|
||||
IF public.isnumeric(vessel_mmsi) IS False THEN
|
||||
vessel_mmsi = NULL;
|
||||
END IF;
|
||||
-- check vessel exist
|
||||
SELECT * INTO vessel_rec
|
||||
FROM auth.vessels vessel
|
||||
WHERE vessel.owner_email = current_setting('request.jwt.claims', true)::json->>'email';
|
||||
IF vessel_rec IS NULL THEN
|
||||
RAISE WARNING 'Register new vessel name:[%] mmsi:[%] for [%]', vessel_name, vessel_mmsi, current_setting('request.jwt.claims', true)::json->>'email';
|
||||
INSERT INTO auth.vessels (owner_email, mmsi, name, role)
|
||||
VALUES (current_setting('request.jwt.claims', true)::json->>'email', vessel_mmsi::NUMERIC, vessel_name, 'vessel_role') RETURNING vessel_id INTO _vessel_id;
|
||||
-- Gather url from app settings
|
||||
app_settings := get_app_settings_fn();
|
||||
-- set oauth user vessel_id attributes for token generation
|
||||
PERFORM keycloak_py_fn(current_setting('request.jwt.claims', true)::json->>'sub'::TEXT, _vessel_id::TEXT, app_settings);
|
||||
END IF;
|
||||
end;
|
||||
$$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.oauth_vessel
|
||||
IS 'user and vessel register entry point from signalk plugin';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- API vessel helper functions
|
||||
-- register_vessel should be on your exposed schema
|
||||
create or replace function
|
||||
api.register_vessel(in vessel_email text, in vessel_mmsi text, in vessel_name text) returns auth.jwt_token as $$
|
||||
declare
|
||||
result auth.jwt_token;
|
||||
app_jwt_secret text;
|
||||
vessel_rec record;
|
||||
_vessel_id text;
|
||||
begin
|
||||
IF vessel_email IS NULL OR vessel_email = ''
|
||||
OR vessel_name IS NULL OR vessel_name = '' THEN
|
||||
RAISE EXCEPTION 'Invalid input'
|
||||
USING HINT = 'Check your parameter';
|
||||
END IF;
|
||||
IF public.isnumeric(vessel_mmsi) IS False THEN
|
||||
vessel_mmsi = NULL;
|
||||
END IF;
|
||||
-- check vessel exist
|
||||
SELECT * INTO vessel_rec
|
||||
FROM auth.vessels vessel
|
||||
WHERE vessel.owner_email = vessel_email;
|
||||
IF vessel_rec IS NULL THEN
|
||||
RAISE WARNING 'Register new vessel name:[%] mmsi:[%] for [%]', vessel_name, vessel_mmsi, vessel_email;
|
||||
INSERT INTO auth.vessels (owner_email, mmsi, name, role)
|
||||
VALUES (vessel_email, vessel_mmsi::NUMERIC, vessel_name, 'vessel_role') RETURNING vessel_id INTO _vessel_id;
|
||||
vessel_rec.role := 'vessel_role';
|
||||
vessel_rec.owner_email = vessel_email;
|
||||
vessel_rec.vessel_id = _vessel_id;
|
||||
END IF;
|
||||
|
||||
-- Get app_jwt_secret
|
||||
SELECT value INTO app_jwt_secret
|
||||
FROM app_settings
|
||||
WHERE name = 'app.jwt_secret';
|
||||
|
||||
select jwt.sign(
|
||||
row_to_json(r)::json, app_jwt_secret
|
||||
) as token
|
||||
from (
|
||||
select vessel_rec.role as role,
|
||||
vessel_rec.owner_email as email, -- TODO replace with user_id
|
||||
-- vessel_rec.user_id as uid
|
||||
vessel_rec.vessel_id as vid
|
||||
) r
|
||||
into result;
|
||||
return result;
|
||||
|
||||
end;
|
||||
$$ language plpgsql security definer;
|
356
initdb/02_5_signalk_api_deps.sql
Normal file
356
initdb/02_5_signalk_api_deps.sql
Normal file
@@ -0,0 +1,356 @@
|
||||
---------------------------------------------------------------------------
|
||||
-- signalk db api schema
|
||||
-- View and Function that have dependency with auth schema
|
||||
|
||||
-- List current database
|
||||
select current_database();
|
||||
|
||||
-- connect to the DB
|
||||
\c signalk
|
||||
|
||||
-- Link auth.vessels with api.metadata
|
||||
--ALTER TABLE api.metadata ADD vessel_id TEXT NOT NULL REFERENCES auth.vessels(vessel_id) ON DELETE RESTRICT;
|
||||
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 via FOREIGN KEY and REFERENCES';
|
||||
|
||||
-- Link auth.vessels with auth.accounts
|
||||
--ALTER TABLE auth.vessels ADD user_id TEXT NOT NULL REFERENCES auth.accounts(user_id) ON DELETE RESTRICT;
|
||||
--COMMENT ON COLUMN auth.vessels.user_id IS 'Link auth.vessels with auth.accounts';
|
||||
--COMMENT ON COLUMN auth.vessels.vessel_id IS 'Vessel identifier. 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
|
||||
DROP VIEW IF EXISTS api.vessels_view;
|
||||
CREATE OR REPLACE VIEW api.vessels_view WITH (security_invoker=true,security_barrier=true) AS
|
||||
WITH metadata AS (
|
||||
SELECT COALESCE(
|
||||
(SELECT m.time
|
||||
FROM api.metadata m
|
||||
WHERE m.vessel_id = current_setting('vessel.id')
|
||||
)::TEXT ,
|
||||
NULL ) as last_contact
|
||||
)
|
||||
SELECT
|
||||
v.name as name,
|
||||
v.mmsi as mmsi,
|
||||
v.created_at as created_at,
|
||||
m.last_contact as last_contact,
|
||||
((NOW() AT TIME ZONE 'UTC' - m.last_contact::TIMESTAMPTZ) > INTERVAL '70 MINUTES') as offline,
|
||||
(NOW() AT TIME ZONE 'UTC' - m.last_contact::TIMESTAMPTZ) as duration
|
||||
FROM auth.vessels v, metadata m
|
||||
WHERE v.owner_email = current_setting('user.email');
|
||||
-- Description
|
||||
COMMENT ON VIEW
|
||||
api.vessels_view
|
||||
IS 'Expose vessels listing to web api';
|
||||
|
||||
DROP FUNCTION IF EXISTS public.has_vessel_fn;
|
||||
CREATE OR REPLACE FUNCTION public.has_vessel_fn() RETURNS BOOLEAN
|
||||
AS $has_vessel$
|
||||
DECLARE
|
||||
BEGIN
|
||||
-- Check a vessel and user exist
|
||||
RETURN (
|
||||
SELECT auth.vessels.name
|
||||
FROM auth.vessels, auth.accounts
|
||||
WHERE auth.vessels.owner_email = auth.accounts.email
|
||||
AND auth.accounts.email = current_setting('user.email')
|
||||
) IS NOT NULL;
|
||||
END;
|
||||
$has_vessel$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.has_vessel_fn
|
||||
IS 'Check if user has a vessel register';
|
||||
|
||||
DROP FUNCTION IF EXISTS public.has_vessel_metadata_fn;
|
||||
CREATE OR REPLACE FUNCTION public.has_vessel_metadata_fn() RETURNS BOOLEAN
|
||||
AS $has_vessel_metadata$
|
||||
DECLARE
|
||||
BEGIN
|
||||
-- Check a vessel metadata
|
||||
RETURN (
|
||||
SELECT m.vessel_id
|
||||
FROM auth.accounts a, auth.vessels v, api.metadata m
|
||||
WHERE m.vessel_id = v.vessel_id
|
||||
AND auth.vessels.owner_email = auth.accounts.email
|
||||
AND auth.accounts.email = current_setting('user.email')
|
||||
) IS NOT NULL;
|
||||
END;
|
||||
$has_vessel_metadata$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.has_vessel_metadata_fn
|
||||
IS 'Check if user has a vessel register';
|
||||
|
||||
-- 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$
|
||||
DECLARE
|
||||
BEGIN
|
||||
SELECT
|
||||
jsonb_build_object(
|
||||
'name', coalesce(m.name, null),
|
||||
'mmsi', coalesce(m.mmsi, null),
|
||||
'created_at', v.created_at,
|
||||
'first_contact', coalesce(m.created_at, null),
|
||||
'last_contact', coalesce(m.time, null),
|
||||
'geojson', coalesce(ST_AsGeoJSON(geojson_t.*)::json, null)
|
||||
)::jsonb || api.vessel_details_fn()::jsonb
|
||||
INTO vessel
|
||||
FROM auth.vessels v, api.metadata m,
|
||||
( select
|
||||
current_setting('vessel.name') as name,
|
||||
time,
|
||||
courseovergroundtrue,
|
||||
speedoverground,
|
||||
anglespeedapparent,
|
||||
longitude,latitude,
|
||||
st_makepoint(longitude,latitude) AS geo_point
|
||||
FROM api.metrics
|
||||
WHERE
|
||||
latitude IS NOT NULL
|
||||
AND longitude IS NOT NULL
|
||||
AND vessel_id = current_setting('vessel.id', false)
|
||||
ORDER BY time DESC LIMIT 1
|
||||
) AS geojson_t
|
||||
WHERE
|
||||
m.vessel_id = current_setting('vessel.id')
|
||||
AND m.vessel_id = v.vessel_id;
|
||||
--RAISE notice 'api.vessel_fn %', obj;
|
||||
END;
|
||||
$vessel$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.vessel_fn
|
||||
IS 'Expose vessel details to API';
|
||||
|
||||
-- Export user settings
|
||||
DROP FUNCTION IF EXISTS api.settings_fn;
|
||||
CREATE OR REPLACE FUNCTION api.settings_fn(out settings json) RETURNS JSON
|
||||
AS $user_settings$
|
||||
BEGIN
|
||||
select row_to_json(row)::json INTO 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_metadata_fn() as has_vessel_metadata,
|
||||
from auth.accounts a
|
||||
where email = current_setting('user.email')
|
||||
) row;
|
||||
END;
|
||||
$user_settings$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.settings_fn
|
||||
IS 'Expose user settings to API';
|
||||
|
||||
DROP FUNCTION IF EXISTS api.versions_fn;
|
||||
CREATE OR REPLACE FUNCTION api.versions_fn() RETURNS JSON
|
||||
AS $version$
|
||||
DECLARE
|
||||
_appv TEXT;
|
||||
_sysv TEXT;
|
||||
BEGIN
|
||||
SELECT
|
||||
value, rtrim(substring(version(), 0, 17)) AS sys_version into _appv,_sysv
|
||||
FROM app_settings
|
||||
WHERE name = 'app.version';
|
||||
RETURN json_build_object('api_version', _appv,
|
||||
'sys_version', _sysv,
|
||||
'timescaledb', (SELECT extversion as timescaledb FROM pg_extension WHERE extname='timescaledb'),
|
||||
'postgis', (SELECT extversion as postgis FROM pg_extension WHERE extname='postgis'),
|
||||
'postgrest', (SELECT rtrim(substring(application_name from 'PostgREST [0-9.]+')) as postgrest FROM pg_stat_activity WHERE application_name ilike '%postgrest%' LIMIT 1));
|
||||
END;
|
||||
$version$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.versions_fn
|
||||
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
|
||||
SELECT
|
||||
value AS api_version,
|
||||
--version() as sys_version
|
||||
rtrim(substring(version(), 0, 17)) AS sys_version,
|
||||
(SELECT extversion as timescaledb FROM pg_extension WHERE extname='timescaledb'),
|
||||
(SELECT extversion as postgis FROM pg_extension WHERE extname='postgis'),
|
||||
(SELECT rtrim(substring(application_name from 'PostgREST [0-9.]+')) as postgrest FROM pg_stat_activity WHERE application_name ilike '%postgrest%' limit 1)
|
||||
FROM app_settings
|
||||
WHERE name = 'app.version';
|
||||
-- Description
|
||||
COMMENT ON VIEW
|
||||
api.versions_view
|
||||
IS 'Expose as a table view app and system version to API';
|
||||
|
||||
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;
|
||||
--RAISE WARNING '-> update_user_preferences_fn update preferences for user [%]', current_setting('request.jwt.claims', true)::json->>'email';
|
||||
UPDATE auth.accounts
|
||||
SET preferences =
|
||||
jsonb_set(preferences::jsonb, key::text[], _value::jsonb)
|
||||
WHERE
|
||||
email = current_setting('user.email', true);
|
||||
IF FOUND THEN
|
||||
--RAISE WARNING '-> update_user_preferences_fn True';
|
||||
RETURN True;
|
||||
END IF;
|
||||
--RAISE WARNING '-> update_user_preferences_fn False';
|
||||
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';
|
||||
|
||||
DROP FUNCTION IF EXISTS api.vessel_details_fn;
|
||||
CREATE OR REPLACE FUNCTION api.vessel_details_fn() RETURNS JSON AS
|
||||
$vessel_details$
|
||||
DECLARE
|
||||
BEGIN
|
||||
RETURN ( WITH tbl AS (
|
||||
SELECT mmsi,ship_type,length,beam,height,plugin_version,platform FROM api.metadata WHERE vessel_id = current_setting('vessel.id', false)
|
||||
)
|
||||
SELECT json_build_object(
|
||||
'ship_type', (SELECT ais.description FROM aistypes ais, tbl t WHERE t.ship_type = ais.id),
|
||||
'country', (SELECT mid.country FROM mid, tbl t WHERE LEFT(cast(t.mmsi as text), 3)::NUMERIC = mid.id),
|
||||
'alpha_2', (SELECT o.alpha_2 FROM mid m, iso3166 o, tbl t WHERE LEFT(cast(t.mmsi as text), 3)::NUMERIC = m.id AND m.country_id = o.id),
|
||||
'length', t.length,
|
||||
'beam', t.beam,
|
||||
'height', t.height,
|
||||
'plugin_version', t.plugin_version,
|
||||
'platform', t.platform)
|
||||
FROM tbl t
|
||||
);
|
||||
END;
|
||||
$vessel_details$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.vessel_details_fn
|
||||
IS 'Return vessel details such as metadata (length,beam,height), ais type and country name and country iso3166-alpha-2';
|
||||
|
||||
DROP VIEW IF EXISTS api.eventlogs_view;
|
||||
CREATE VIEW api.eventlogs_view WITH (security_invoker=true,security_barrier=true) AS
|
||||
SELECT pq.*
|
||||
FROM public.process_queue pq
|
||||
WHERE channel <> 'pre_logbook' AND (ref_id = current_setting('user.id', true)
|
||||
OR ref_id = current_setting('vessel.id', true))
|
||||
ORDER BY id ASC;
|
||||
-- Description
|
||||
COMMENT ON VIEW
|
||||
api.eventlogs_view
|
||||
IS 'Event logs view';
|
||||
|
||||
DROP FUNCTION IF EXISTS api.update_logbook_observations_fn;
|
||||
-- Update/Add a specific user observations into logbook
|
||||
CREATE OR REPLACE FUNCTION api.update_logbook_observations_fn(IN _id INT, IN observations TEXT) RETURNS BOOLEAN AS
|
||||
$update_logbook_observations$
|
||||
DECLARE
|
||||
BEGIN
|
||||
-- Merge existing observations with the new observations objects
|
||||
RAISE NOTICE '-> update_logbook_extra_fn id:[%] observations:[%]', _id, observations;
|
||||
-- { 'observations': { 'seaState': -1, 'cloudCoverage': -1, 'visibility': -1 } }
|
||||
UPDATE api.logbook SET extra = public.jsonb_recursive_merge(extra, observations::jsonb) WHERE id = _id;
|
||||
IF FOUND IS True THEN
|
||||
RETURN True;
|
||||
END IF;
|
||||
RETURN False;
|
||||
END;
|
||||
$update_logbook_observations$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.update_logbook_observations_fn
|
||||
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 or replace FUNCTION api.ispublic_fn(IN boat TEXT, IN _type TEXT, IN _id INTEGER DEFAULT NULL) RETURNS BOOLEAN AS $ispublic$
|
||||
DECLARE
|
||||
vessel TEXT := '^' || boat || '$';
|
||||
anonymous BOOLEAN := False;
|
||||
valid_public_type BOOLEAN := False;
|
||||
public_logs BOOLEAN := False;
|
||||
BEGIN
|
||||
-- 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
|
||||
SELECT _type::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 WARNING '-> ispublic_fn invalid input type %', _type;
|
||||
RETURN False;
|
||||
END IF;
|
||||
|
||||
RAISE WARNING '-> ispublic_fn _type [%], _id [%]', _type, _id;
|
||||
IF _type ~ '^public_(logs|timelapse)$' AND _id > 0 THEN
|
||||
WITH log as (
|
||||
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 a.preferences->>'public_vessel'::text ~* vessel
|
||||
AND prefs.key = _type::TEXT
|
||||
AND prefs.value::BOOLEAN = true
|
||||
) 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
|
||||
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
|
||||
$ispublic$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.ispublic_fn
|
||||
IS 'Is web page publicly accessible by register boat name and/or logbook id';
|
513
initdb/02_5_signalk_auth_otp.sql
Normal file
513
initdb/02_5_signalk_auth_otp.sql
Normal file
@@ -0,0 +1,513 @@
|
||||
---------------------------------------------------------------------------
|
||||
-- signalk db auth schema
|
||||
-- View and Function that have dependency with auth schema
|
||||
|
||||
-- List current database
|
||||
select current_database();
|
||||
|
||||
-- connect to the DB
|
||||
\c signalk
|
||||
|
||||
DROP TABLE IF EXISTS auth.otp;
|
||||
CREATE TABLE IF NOT EXISTS auth.otp (
|
||||
-- update email type to CITEXT, https://www.postgresql.org/docs/current/citext.html
|
||||
user_email CITEXT NOT NULL PRIMARY KEY REFERENCES auth.accounts(email) ON DELETE RESTRICT,
|
||||
otp_pass TEXT NOT NULL,
|
||||
otp_timestamp TIMESTAMPTZ DEFAULT NOW(),
|
||||
otp_tries SMALLINT NOT NULL DEFAULT '0'
|
||||
);
|
||||
-- Description
|
||||
COMMENT ON TABLE
|
||||
auth.otp
|
||||
IS 'Stores temporal otp code for up to 15 minutes';
|
||||
-- Indexes
|
||||
CREATE INDEX otp_pass_idx ON auth.otp (otp_pass);
|
||||
-- Duplicate Indexes
|
||||
--CREATE INDEX otp_user_email_idx ON auth.otp (user_email);
|
||||
|
||||
DROP FUNCTION IF EXISTS public.generate_uid_fn;
|
||||
CREATE OR REPLACE FUNCTION public.generate_uid_fn(size INT) RETURNS TEXT
|
||||
AS $generate_uid_fn$
|
||||
DECLARE
|
||||
characters TEXT := '0123456789';
|
||||
bytes BYTEA := gen_random_bytes(size);
|
||||
l INT := length(characters);
|
||||
i INT := 0;
|
||||
output TEXT := '';
|
||||
BEGIN
|
||||
WHILE i < size LOOP
|
||||
output := output || substr(characters, get_byte(bytes, i) % l + 1, 1);
|
||||
i := i + 1;
|
||||
END LOOP;
|
||||
RETURN output;
|
||||
END;
|
||||
$generate_uid_fn$ LANGUAGE plpgsql VOLATILE;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.generate_uid_fn
|
||||
IS 'Generate a random digit';
|
||||
|
||||
-- gerenate a OTP code by email
|
||||
-- Expose as an API endpoint
|
||||
DROP FUNCTION IF EXISTS api.generate_otp_fn;
|
||||
CREATE OR REPLACE FUNCTION api.generate_otp_fn(IN email TEXT) RETURNS TEXT
|
||||
AS $generate_otp$
|
||||
DECLARE
|
||||
_email CITEXT := email;
|
||||
_email_check TEXT := NULL;
|
||||
_otp_pass VARCHAR(10) := NULL;
|
||||
BEGIN
|
||||
IF email IS NULL OR _email IS NULL OR _email = '' THEN
|
||||
RAISE EXCEPTION 'invalid input' USING HINT = 'check your parameter';
|
||||
END IF;
|
||||
SELECT lower(a.email) INTO _email_check FROM auth.accounts a WHERE a.email = _email;
|
||||
IF _email_check IS NULL THEN
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
--SELECT substr(gen_random_uuid()::text, 1, 6) INTO otp_pass;
|
||||
SELECT generate_uid_fn(6) INTO _otp_pass;
|
||||
-- upsert - Insert or update otp code on conflit
|
||||
INSERT INTO auth.otp (user_email, otp_pass)
|
||||
VALUES (_email_check, _otp_pass)
|
||||
ON CONFLICT (user_email) DO UPDATE SET otp_pass = _otp_pass, otp_timestamp = NOW();
|
||||
RETURN _otp_pass;
|
||||
END;
|
||||
$generate_otp$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.generate_otp_fn
|
||||
IS 'Generate otp code';
|
||||
|
||||
DROP FUNCTION IF EXISTS api.recover;
|
||||
CREATE OR REPLACE FUNCTION api.recover(in email text) returns BOOLEAN
|
||||
AS $recover_fn$
|
||||
DECLARE
|
||||
_email CITEXT := email;
|
||||
_user_id TEXT := NULL;
|
||||
otp_pass TEXT := NULL;
|
||||
_reset_qs TEXT := NULL;
|
||||
user_settings jsonb := NULL;
|
||||
BEGIN
|
||||
IF _email IS NULL OR _email = '' THEN
|
||||
RAISE EXCEPTION 'Invalid input'
|
||||
USING HINT = 'Check your parameter';
|
||||
END IF;
|
||||
SELECT user_id INTO _user_id FROM auth.accounts a WHERE a.email = _email;
|
||||
IF NOT FOUND THEN
|
||||
RAISE EXCEPTION 'Invalid input'
|
||||
USING HINT = 'Check your parameter';
|
||||
END IF;
|
||||
-- Generate OTP
|
||||
otp_pass := api.generate_otp_fn(email);
|
||||
SELECT CONCAT('uuid=', _user_id, '&token=', otp_pass) INTO _reset_qs;
|
||||
-- Enable email_notifications
|
||||
PERFORM api.update_user_preferences_fn('{email_notifications}'::TEXT, True::TEXT);
|
||||
-- Send email/notifications
|
||||
user_settings := '{"email": "' || _email || '", "reset_qs": "' || _reset_qs || '"}';
|
||||
PERFORM send_notification_fn('email_reset'::TEXT, user_settings::JSONB);
|
||||
RETURN TRUE;
|
||||
END;
|
||||
$recover_fn$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.recover
|
||||
IS 'Send recover password email to reset password';
|
||||
|
||||
DROP FUNCTION IF EXISTS api.reset;
|
||||
CREATE OR REPLACE FUNCTION api.reset(in pass text, in token text, in uuid text) returns BOOLEAN
|
||||
AS $reset_fn$
|
||||
DECLARE
|
||||
_email TEXT := NULL;
|
||||
_pass TEXT := pass;
|
||||
BEGIN
|
||||
-- Check parameters
|
||||
IF token IS NULL OR uuid IS NULL OR pass IS NULL THEN
|
||||
RAISE EXCEPTION 'invalid input' USING HINT = 'check your parameter';
|
||||
END IF;
|
||||
-- Verify token
|
||||
SELECT auth.verify_otp_fn(token) INTO _email;
|
||||
IF _email IS NOT NULL THEN
|
||||
SELECT email INTO _email FROM auth.accounts WHERE user_id = uuid;
|
||||
IF _email IS NULL THEN
|
||||
RETURN False;
|
||||
END IF;
|
||||
-- Set user new password
|
||||
UPDATE auth.accounts
|
||||
SET pass = _pass
|
||||
WHERE email = _email;
|
||||
-- Enable email_validation into user preferences
|
||||
PERFORM api.update_user_preferences_fn('{email_valid}'::TEXT, True::TEXT);
|
||||
-- Enable email_notifications
|
||||
PERFORM api.update_user_preferences_fn('{email_notifications}'::TEXT, True::TEXT);
|
||||
-- Delete token when validated
|
||||
DELETE FROM auth.otp
|
||||
WHERE user_email = _email;
|
||||
RETURN True;
|
||||
END IF;
|
||||
RETURN False;
|
||||
END;
|
||||
$reset_fn$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.reset
|
||||
IS 'Reset user password base on otp code and user_id send by email from api.recover';
|
||||
|
||||
DROP FUNCTION IF EXISTS auth.verify_otp_fn;
|
||||
CREATE OR REPLACE FUNCTION auth.verify_otp_fn(IN token TEXT) RETURNS TEXT
|
||||
AS $verify_otp$
|
||||
DECLARE
|
||||
email TEXT := NULL;
|
||||
BEGIN
|
||||
IF token IS NULL THEN
|
||||
RAISE EXCEPTION 'invalid input' USING HINT = 'check your parameter';
|
||||
END IF;
|
||||
-- Token is valid 15 minutes
|
||||
SELECT user_email INTO email
|
||||
FROM auth.otp
|
||||
WHERE otp_timestamp > NOW() AT TIME ZONE 'UTC' - INTERVAL '15 MINUTES'
|
||||
AND otp_tries < 3
|
||||
AND otp_pass = token;
|
||||
RETURN email;
|
||||
END;
|
||||
$verify_otp$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
auth.verify_otp_fn
|
||||
IS 'Verify OTP';
|
||||
|
||||
-- CRON to purge OTP older than 15 minutes
|
||||
DROP FUNCTION IF EXISTS public.cron_process_prune_otp_fn;
|
||||
CREATE OR REPLACE FUNCTION public.cron_process_prune_otp_fn() RETURNS void
|
||||
AS $$
|
||||
DECLARE
|
||||
otp_rec record;
|
||||
BEGIN
|
||||
-- Purge OTP older than 15 minutes
|
||||
RAISE NOTICE 'cron_process_prune_otp_fn';
|
||||
FOR otp_rec in
|
||||
SELECT *
|
||||
FROM auth.otp
|
||||
WHERE otp_timestamp < NOW() AT TIME ZONE 'UTC' - INTERVAL '15 MINUTES'
|
||||
ORDER BY otp_timestamp desc
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_process_prune_otp_fn deleting expired otp for user [%]', otp_rec.user_email;
|
||||
-- remove entry
|
||||
DELETE FROM auth.otp
|
||||
WHERE user_email = otp_rec.user_email;
|
||||
RAISE NOTICE '-> cron_process_prune_otp_fn deleted expire otp for user [%]', otp_rec.user_email;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_process_prune_otp_fn
|
||||
IS 'init by pg_cron to purge older than 15 minutes OTP token';
|
||||
|
||||
-- Email OTP validation
|
||||
-- Expose as an API endpoint
|
||||
DROP FUNCTION IF EXISTS api.email_fn;
|
||||
CREATE OR REPLACE FUNCTION api.email_fn(IN token TEXT) RETURNS BOOLEAN
|
||||
AS $email_validation$
|
||||
DECLARE
|
||||
_email TEXT := NULL;
|
||||
BEGIN
|
||||
-- Check parameters
|
||||
IF token IS NULL THEN
|
||||
RAISE EXCEPTION 'invalid input' USING HINT = 'check your parameter';
|
||||
END IF;
|
||||
-- Verify token
|
||||
SELECT auth.verify_otp_fn(token) INTO _email;
|
||||
IF _email IS NOT NULL THEN
|
||||
-- Check the email JWT token match the OTP email
|
||||
IF current_setting('user.email', true) <> _email THEN
|
||||
RETURN False;
|
||||
END IF;
|
||||
-- Set user email into env to allow RLS update
|
||||
--PERFORM set_config('user.email', _email, false);
|
||||
-- Enable email_validation into user preferences
|
||||
PERFORM api.update_user_preferences_fn('{email_valid}'::TEXT, True::TEXT);
|
||||
-- Enable email_notifications
|
||||
PERFORM api.update_user_preferences_fn('{email_notifications}'::TEXT, True::TEXT);
|
||||
-- Delete token when validated
|
||||
DELETE FROM auth.otp
|
||||
WHERE user_email = _email;
|
||||
-- Disable to reduce spam
|
||||
-- Send Notification async
|
||||
--INSERT INTO process_queue (channel, payload, stored)
|
||||
-- VALUES ('email_valid', _email, now());
|
||||
RETURN True;
|
||||
END IF;
|
||||
RETURN False;
|
||||
END;
|
||||
$email_validation$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.email_fn
|
||||
IS 'Store email_valid into user preferences if valid token/otp';
|
||||
|
||||
-- Pushover Subscription API
|
||||
-- Web-Based Subscription Process
|
||||
-- https://pushover.net/api/subscriptions#web
|
||||
-- Expose as an API endpoint
|
||||
CREATE OR REPLACE FUNCTION api.pushover_subscribe_link_fn(OUT pushover_link JSON) RETURNS JSON
|
||||
AS $pushover_subscribe_link$
|
||||
DECLARE
|
||||
app_url text;
|
||||
otp_code text;
|
||||
pushover_app_url text;
|
||||
success text;
|
||||
failure text;
|
||||
email text := current_setting('user.email', true);
|
||||
BEGIN
|
||||
--https://pushover.net/api/subscriptions#web
|
||||
-- "https://pushover.net/subscribe/PostgSail-23uvrho1d5y6n3e"
|
||||
-- + "?success=" + urlencode("https://beta.openplotter.cloud/api/rpc/pushover_fn?token=" + generate_otp_fn({{email}}))
|
||||
-- + "&failure=" + urlencode("https://beta.openplotter.cloud/settings");
|
||||
-- get app_url
|
||||
SELECT
|
||||
value INTO app_url
|
||||
FROM
|
||||
public.app_settings
|
||||
WHERE
|
||||
name = 'app.url';
|
||||
-- get pushover url subscribe
|
||||
SELECT
|
||||
value INTO pushover_app_url
|
||||
FROM
|
||||
public.app_settings
|
||||
WHERE
|
||||
name = 'app.pushover_app_url';
|
||||
-- Generate OTP
|
||||
otp_code := api.generate_otp_fn(email);
|
||||
-- On success redirect to API endpoint
|
||||
SELECT CONCAT(
|
||||
'?success=',
|
||||
public.urlescape_py_fn(CONCAT(app_url,'/pushover?token=')),
|
||||
otp_code)
|
||||
INTO success;
|
||||
-- On failure redirect to user settings, where he does come from
|
||||
SELECT CONCAT(
|
||||
'&failure=',
|
||||
public.urlescape_py_fn(CONCAT(app_url,'/profile'))
|
||||
) INTO failure;
|
||||
SELECT json_build_object('link', CONCAT(pushover_app_url, success, failure)) INTO pushover_link;
|
||||
END;
|
||||
$pushover_subscribe_link$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.pushover_subscribe_link_fn
|
||||
IS 'Generate Pushover subscription link';
|
||||
|
||||
-- Confirm Pushover Subscription
|
||||
-- Web-Based Subscription Process
|
||||
-- https://pushover.net/api/subscriptions#web
|
||||
-- Expose as an API endpoint
|
||||
DROP FUNCTION IF EXISTS api.pushover_fn;
|
||||
CREATE OR REPLACE FUNCTION api.pushover_fn(IN token TEXT, IN pushover_user_key TEXT) RETURNS BOOLEAN
|
||||
AS $pushover$
|
||||
DECLARE
|
||||
_email TEXT := NULL;
|
||||
BEGIN
|
||||
-- Check parameters
|
||||
IF token IS NULL OR pushover_user_key IS NULL THEN
|
||||
RAISE EXCEPTION 'invalid input' USING HINT = 'check your parameter';
|
||||
END IF;
|
||||
-- Verify token
|
||||
SELECT auth.verify_otp_fn(token) INTO _email;
|
||||
IF _email IS NOT NULL THEN
|
||||
-- Set user email into env to allow RLS update
|
||||
PERFORM set_config('user.email', _email, false);
|
||||
-- Add pushover_user_key into user preferences
|
||||
PERFORM api.update_user_preferences_fn('{pushover_user_key}'::TEXT, pushover_user_key::TEXT);
|
||||
-- Enable phone_notifications
|
||||
PERFORM api.update_user_preferences_fn('{phone_notifications}'::TEXT, True::TEXT);
|
||||
-- Delete token when validated
|
||||
DELETE FROM auth.otp
|
||||
WHERE user_email = _email;
|
||||
-- Disable Notification because
|
||||
-- Pushover send a notification when sucesssful with the description of the app
|
||||
--
|
||||
-- Send Notification async
|
||||
--INSERT INTO process_queue (channel, payload, stored)
|
||||
-- VALUES ('pushover_valid', _email, now());
|
||||
RETURN True;
|
||||
END IF;
|
||||
RETURN False;
|
||||
END;
|
||||
$pushover$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.pushover_fn
|
||||
IS 'Confirm Pushover Subscription and store pushover_user_key into user preferences if provide a valid OTP token';
|
||||
|
||||
-- Telegram OTP Validation
|
||||
-- Expose as an API endpoint
|
||||
DROP FUNCTION IF EXISTS api.telegram_fn;
|
||||
CREATE OR REPLACE FUNCTION api.telegram_fn(IN token TEXT, IN telegram_obj TEXT) RETURNS BOOLEAN
|
||||
AS $telegram$
|
||||
DECLARE
|
||||
_email TEXT := NULL;
|
||||
user_settings jsonb;
|
||||
BEGIN
|
||||
-- Check parameters
|
||||
IF token IS NULL OR telegram_obj IS NULL THEN
|
||||
RAISE EXCEPTION 'invalid input' USING HINT = 'check your parameter';
|
||||
END IF;
|
||||
-- Verify token
|
||||
SELECT auth.verify_otp_fn(token) INTO _email;
|
||||
IF _email IS NOT NULL THEN
|
||||
-- Set user email into env to allow RLS update
|
||||
PERFORM set_config('user.email', _email, false);
|
||||
-- Add telegram obj into user preferences
|
||||
PERFORM api.update_user_preferences_fn('{telegram}'::TEXT, telegram_obj::TEXT);
|
||||
-- Delete token when validated
|
||||
DELETE FROM auth.otp
|
||||
WHERE user_email = _email;
|
||||
-- Send Notification async
|
||||
--INSERT INTO process_queue (channel, payload, stored)
|
||||
-- VALUES ('telegram_valid', _email, now());
|
||||
RETURN True;
|
||||
END IF;
|
||||
RETURN False;
|
||||
END;
|
||||
$telegram$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.telegram_fn
|
||||
IS 'Confirm telegram user and store telegram chat details into user preferences if provide a valid OTP token';
|
||||
|
||||
-- Telegram user validation
|
||||
DROP FUNCTION IF EXISTS auth.telegram_user_exists_fn;
|
||||
CREATE OR REPLACE FUNCTION auth.telegram_user_exists_fn(IN email TEXT, IN user_id BIGINT) RETURNS BOOLEAN
|
||||
AS $telegram_user_exists$
|
||||
DECLARE
|
||||
_email CITEXT := email;
|
||||
_user_id BIGINT := user_id;
|
||||
BEGIN
|
||||
IF _email IS NULL OR _chat_id IS NULL THEN
|
||||
RAISE EXCEPTION 'invalid input' USING HINT = 'check your parameter';
|
||||
END IF;
|
||||
-- Does user and telegram obj
|
||||
SELECT preferences->'telegram'->'from'->'id' INTO _user_id
|
||||
FROM auth.accounts a
|
||||
WHERE a.email = _email
|
||||
AND cast(preferences->'telegram'->'from'->'id' as BIGINT) = _user_id::BIGINT;
|
||||
IF FOUND THEN
|
||||
RETURN TRUE;
|
||||
END IF;
|
||||
RETURN FALSE;
|
||||
END;
|
||||
$telegram_user_exists$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
auth.telegram_user_exists_fn
|
||||
IS 'Check if user exist based on email and user_id';
|
||||
|
||||
-- Telegram otp validation
|
||||
DROP FUNCTION IF EXISTS api.telegram_otp_fn;
|
||||
CREATE OR REPLACE FUNCTION api.telegram_otp_fn(IN email TEXT, OUT otp_code TEXT) RETURNS TEXT
|
||||
AS $telegram_otp$
|
||||
DECLARE
|
||||
_email CITEXT := email;
|
||||
user_settings jsonb := NULL;
|
||||
BEGIN
|
||||
IF _email IS NULL THEN
|
||||
RAISE EXCEPTION 'invalid input' USING HINT = 'check your parameter';
|
||||
END IF;
|
||||
-- Generate token
|
||||
otp_code := api.generate_otp_fn(_email);
|
||||
IF otp_code IS NOT NULL THEN
|
||||
-- Set user email into env to allow RLS update
|
||||
PERFORM set_config('user.email', _email, false);
|
||||
-- Send Notification
|
||||
user_settings := '{"email": "' || _email || '", "otp_code": "' || otp_code || '"}';
|
||||
PERFORM send_notification_fn('telegram_otp'::TEXT, user_settings::JSONB);
|
||||
END IF;
|
||||
END;
|
||||
$telegram_otp$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.telegram_otp_fn
|
||||
IS 'Telegram otp generation';
|
||||
|
||||
-- Telegram JWT auth
|
||||
-- Expose as an API endpoint
|
||||
-- Avoid sending a password so use email and chat_id as key pair
|
||||
DROP FUNCTION IF EXISTS api.telegram;
|
||||
CREATE OR REPLACE FUNCTION api.telegram(IN user_id BIGINT, IN email TEXT DEFAULT NULL) RETURNS auth.jwt_token
|
||||
AS $telegram_jwt$
|
||||
DECLARE
|
||||
_email TEXT := email;
|
||||
_user_id BIGINT := user_id;
|
||||
_uid TEXT := NULL;
|
||||
_exist BOOLEAN := False;
|
||||
result auth.jwt_token;
|
||||
app_jwt_secret text;
|
||||
BEGIN
|
||||
IF _user_id IS NULL THEN
|
||||
RAISE EXCEPTION 'invalid input' USING HINT = 'check your parameter';
|
||||
END IF;
|
||||
|
||||
-- Check _user_id
|
||||
SELECT auth.telegram_session_exists_fn(_user_id) into _exist;
|
||||
IF _exist IS NULL OR _exist <> True THEN
|
||||
--RAISE EXCEPTION 'invalid input' USING HINT = 'check your parameter';
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
|
||||
-- Get email and user_id
|
||||
SELECT a.email,a.user_id INTO _email,_uid
|
||||
FROM auth.accounts a
|
||||
WHERE cast(preferences->'telegram'->'from'->'id' as BIGINT) = _user_id::BIGINT;
|
||||
|
||||
-- Get app_jwt_secret
|
||||
SELECT value INTO app_jwt_secret
|
||||
FROM app_settings
|
||||
WHERE name = 'app.jwt_secret';
|
||||
|
||||
-- Generate JWT token, force user_role
|
||||
select jwt.sign(
|
||||
row_to_json(r)::json, app_jwt_secret
|
||||
) as token
|
||||
from (
|
||||
select 'user_role' as role,
|
||||
(select lower(_email)) as email,
|
||||
_uid as uid,
|
||||
extract(epoch from now())::integer + 60*60 as exp
|
||||
) r
|
||||
into result;
|
||||
return result;
|
||||
END;
|
||||
$telegram_jwt$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.telegram
|
||||
IS 'Generate a JWT user_role token based on chat_id from telegram';
|
||||
|
||||
-- Telegram chat_id session validation
|
||||
DROP FUNCTION IF EXISTS auth.telegram_session_exists_fn;
|
||||
CREATE OR REPLACE FUNCTION auth.telegram_session_exists_fn(IN user_id BIGINT) RETURNS BOOLEAN
|
||||
AS $telegram_session_exists$
|
||||
DECLARE
|
||||
_id BIGINT := NULL;
|
||||
_user_id BIGINT := user_id;
|
||||
_email TEXT := NULL;
|
||||
BEGIN
|
||||
IF user_id IS NULL THEN
|
||||
RAISE EXCEPTION 'invalid input' USING HINT = 'check your parameter';
|
||||
END IF;
|
||||
|
||||
-- Find user email based on telegram chat_id
|
||||
SELECT preferences->'telegram'->'from'->'id' INTO _id
|
||||
FROM auth.accounts a
|
||||
WHERE cast(preferences->'telegram'->'from'->'id' as BIGINT) = _user_id::BIGINT;
|
||||
IF FOUND THEN
|
||||
RETURN True;
|
||||
END IF;
|
||||
RETURN FALSE;
|
||||
END;
|
||||
$telegram_session_exists$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
auth.telegram_session_exists_fn
|
||||
IS 'Check if session/user exist based on user_id';
|
379
initdb/02_6_signalk_roles.sql
Normal file
379
initdb/02_6_signalk_roles.sql
Normal file
@@ -0,0 +1,379 @@
|
||||
---------------------------------------------------------------------------
|
||||
-- singalk db permissions
|
||||
--
|
||||
|
||||
-- List current database
|
||||
select current_database();
|
||||
|
||||
-- connect to the DB
|
||||
\c signalk
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Permissions roles
|
||||
-- Users Sharing Role
|
||||
-- https://postgrest.org/en/stable/auth.html#web-users-sharing-role
|
||||
--
|
||||
-- api_anonymous
|
||||
-- nologin
|
||||
-- api_anonymous role in the database with which to execute anonymous web requests, limit 20 connections
|
||||
-- api_anonymous allows JWT token generation with an expiration time via function api.login() from auth.accounts table
|
||||
create role api_anonymous WITH NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOLOGIN NOBYPASSRLS NOREPLICATION CONNECTION LIMIT 20;
|
||||
comment on role api_anonymous is
|
||||
'The role that PostgREST will switch to when a user is not authenticated.';
|
||||
-- Limit to 20 connections
|
||||
--alter user api_anonymous connection limit 20;
|
||||
grant usage on schema api to api_anonymous;
|
||||
-- explicitly limit EXECUTE privileges to only signup and login and reset functions
|
||||
grant execute on function api.login(text,text) to api_anonymous;
|
||||
grant execute on function api.signup(text,text,text,text) to api_anonymous;
|
||||
grant execute on function api.recover(text) to api_anonymous;
|
||||
grant execute on function api.reset(text,text,text) to api_anonymous;
|
||||
-- explicitly limit EXECUTE privileges to pgrest db-pre-request function
|
||||
grant execute on function public.check_jwt() to api_anonymous;
|
||||
-- explicitly limit EXECUTE privileges to only telegram jwt auth function
|
||||
grant execute on function api.telegram(bigint,text) to api_anonymous;
|
||||
-- explicitly limit EXECUTE privileges to only pushover subscription validation function
|
||||
grant execute on function api.email_fn(text) to api_anonymous;
|
||||
grant execute on function api.pushover_fn(text,text) to api_anonymous;
|
||||
grant execute on function api.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(text,text,integer) to api_anonymous;
|
||||
grant execute on function api.timelapse_fn to api_anonymous;
|
||||
grant execute on function api.stats_logs_fn to api_anonymous;
|
||||
grant execute on function api.stats_stays_fn to api_anonymous;
|
||||
grant execute on function api.status_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
|
||||
create role authenticator NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT login password 'mysecretpassword';
|
||||
comment on role authenticator is
|
||||
'Role that serves as an entry-point for API servers such as PostgREST.';
|
||||
grant api_anonymous to authenticator;
|
||||
|
||||
-- Grafana user and role with login, read-only, limit 20 connections
|
||||
CREATE ROLE grafana WITH NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOBYPASSRLS NOREPLICATION CONNECTION LIMIT 20 LOGIN PASSWORD 'mysecretpassword';
|
||||
comment on role grafana is
|
||||
'Role that grafana will use for authenticated web users.';
|
||||
-- Allow API schema and Tables
|
||||
GRANT USAGE ON SCHEMA api TO grafana;
|
||||
-- Allow read on SEQUENCE on API schema
|
||||
GRANT USAGE, SELECT ON SEQUENCE api.logbook_id_seq,api.metadata_id_seq,api.moorages_id_seq,api.stays_id_seq TO grafana;
|
||||
-- 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 grafana;
|
||||
-- Allow read on VIEWS on API schema
|
||||
GRANT SELECT ON TABLE api.logs_view,api.moorages_view,api.stays_view TO grafana;
|
||||
GRANT SELECT ON TABLE api.log_view,api.moorage_view,api.stay_view,api.vessels_view TO grafana;
|
||||
GRANT SELECT ON TABLE api.monitoring_view,api.monitoring_view2,api.monitoring_view3 TO grafana;
|
||||
GRANT SELECT ON TABLE api.monitoring_humidity,api.monitoring_voltage,api.monitoring_temperatures TO grafana;
|
||||
-- Allow Auth schema and Tables
|
||||
GRANT USAGE ON SCHEMA auth TO grafana;
|
||||
GRANT SELECT ON TABLE auth.vessels TO grafana;
|
||||
GRANT EXECUTE ON FUNCTION public.citext_eq(citext, citext) TO grafana;
|
||||
|
||||
-- Grafana_auth authenticator user and role with login, read-only on auth.accounts, limit 20 connections
|
||||
CREATE ROLE grafana_auth WITH NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOBYPASSRLS NOREPLICATION CONNECTION LIMIT 20 LOGIN PASSWORD 'mysecretpassword';
|
||||
comment on role grafana_auth is
|
||||
'Role that grafana auth proxy authenticator via apache.';
|
||||
-- Allow read on VIEWS on API schema
|
||||
GRANT USAGE ON SCHEMA api TO grafana_auth;
|
||||
GRANT SELECT ON TABLE api.metadata TO grafana_auth;
|
||||
-- Allow Auth schema and Tables
|
||||
GRANT USAGE ON SCHEMA auth TO grafana_auth;
|
||||
GRANT SELECT ON TABLE auth.accounts TO grafana_auth;
|
||||
GRANT SELECT ON TABLE auth.vessels TO grafana_auth;
|
||||
-- GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public TO grafana_auth;
|
||||
GRANT EXECUTE ON FUNCTION public.citext_eq(citext, citext) TO grafana_auth;
|
||||
GRANT ALL ON SCHEMA public TO grafana_auth; -- Important if grafana database in pg
|
||||
|
||||
-- User:
|
||||
-- nologin, web api only
|
||||
-- read-only for all and Read on logbook, stays and moorage and Write only for specific (name, notes) COLUMNS
|
||||
CREATE ROLE user_role WITH NOLOGIN NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOBYPASSRLS NOREPLICATION;
|
||||
comment on role user_role is
|
||||
'Role that PostgREST will switch to for authenticated web users.';
|
||||
GRANT user_role to authenticator;
|
||||
GRANT USAGE ON SCHEMA api TO user_role;
|
||||
-- Allow read on SEQUENCE on API schema
|
||||
GRANT USAGE, SELECT ON SEQUENCE api.logbook_id_seq,api.metadata_id_seq,api.moorages_id_seq,api.stays_id_seq TO user_role;
|
||||
-- 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 user_role;
|
||||
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, _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;
|
||||
|
||||
-- pg15 feature security_invoker=true,security_barrier=true
|
||||
GRANT SELECT ON TABLE api.logs_view,api.moorages_view,api.stays_view TO user_role;
|
||||
GRANT SELECT ON TABLE api.log_view,api.moorage_view,api.stay_view,api.vessels_view TO user_role;
|
||||
GRANT SELECT ON TABLE api.monitoring_view,api.monitoring_view2,api.monitoring_view3,api.explore_view TO user_role;
|
||||
GRANT SELECT ON TABLE api.monitoring_humidity,api.monitoring_voltage,api.monitoring_temperatures TO user_role;
|
||||
GRANT SELECT ON TABLE api.stats_moorages_away_view,api.versions_view TO user_role;
|
||||
GRANT SELECT ON TABLE api.total_info_view TO user_role;
|
||||
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
|
||||
-- insert-update-only for api.metrics,api.logbook,api.moorages,api.stays,api.metadata and sequences and process_queue
|
||||
CREATE ROLE vessel_role WITH NOLOGIN NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOBYPASSRLS NOREPLICATION;
|
||||
comment on role vessel_role is
|
||||
'Role that PostgREST will switch to for authenticated web vessels.';
|
||||
GRANT vessel_role to authenticator;
|
||||
GRANT USAGE ON SCHEMA api TO vessel_role;
|
||||
-- Allow read on SEQUENCE on API schema
|
||||
GRANT USAGE, SELECT ON SEQUENCE api.logbook_id_seq,api.metadata_id_seq,api.moorages_id_seq,api.stays_id_seq TO vessel_role;
|
||||
-- Allow read/write on TABLES on API schema
|
||||
GRANT INSERT, UPDATE, SELECT ON TABLE api.metrics,api.logbook,api.moorages,api.stays,api.metadata TO vessel_role;
|
||||
GRANT INSERT ON TABLE public.process_queue TO vessel_role;
|
||||
GRANT USAGE, SELECT ON SEQUENCE public.process_queue_id_seq TO vessel_role;
|
||||
-- explicitly limit EXECUTE privileges to pgrest db-pre-request function
|
||||
GRANT EXECUTE ON FUNCTION public.check_jwt() to vessel_role;
|
||||
-- explicitly limit EXECUTE privileges to api.metrics triggers function
|
||||
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;
|
||||
-- Oauth registration
|
||||
GRANT EXECUTE ON FUNCTION api.oauth() TO vessel_role;
|
||||
GRANT EXECUTE ON FUNCTION api.oauth_vessel(text,text) TO vessel_role;
|
||||
|
||||
--- Scheduler:
|
||||
-- TODO: currently cron function are run as super user, switch to scheduler role.
|
||||
-- Scheduler read-only all, and write on api.logbook, api.stays, api.moorages, public.process_queue, auth.otp
|
||||
-- Crons
|
||||
--CREATE ROLE scheduler WITH NOLOGIN NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOBYPASSRLS NOREPLICATION;
|
||||
CREATE ROLE scheduler WITH NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOBYPASSRLS NOREPLICATION CONNECTION LIMIT 10 LOGIN;
|
||||
comment on role scheduler is
|
||||
'Role that pgcron will use to process logbook,moorages,stays,monitoring and notification.';
|
||||
GRANT scheduler to authenticator;
|
||||
GRANT USAGE ON SCHEMA api TO scheduler;
|
||||
GRANT SELECT ON TABLE api.metrics,api.metadata TO scheduler;
|
||||
GRANT INSERT, UPDATE, SELECT ON TABLE api.logbook,api.moorages,api.stays TO scheduler;
|
||||
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public TO scheduler;
|
||||
GRANT SELECT ON ALL TABLES IN SCHEMA public TO scheduler;
|
||||
GRANT SELECT,UPDATE ON TABLE public.process_queue TO scheduler;
|
||||
GRANT USAGE ON SCHEMA auth TO scheduler;
|
||||
GRANT SELECT ON ALL TABLES IN SCHEMA auth TO scheduler;
|
||||
GRANT SELECT,UPDATE,DELETE ON TABLE auth.otp TO scheduler;
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Security policy
|
||||
-- ROW LEVEL Security policy
|
||||
|
||||
ALTER TABLE api.metadata ENABLE ROW LEVEL SECURITY;
|
||||
-- Administrator can see all rows and add any rows
|
||||
CREATE POLICY admin_all ON api.metadata TO current_user
|
||||
USING (true)
|
||||
WITH CHECK (true);
|
||||
-- Allow vessel_role to insert and select on their own records
|
||||
CREATE POLICY api_vessel_role ON api.metadata TO vessel_role
|
||||
USING (vessel_id = current_setting('vessel.id', false))
|
||||
WITH CHECK (true);
|
||||
-- Allow user_role to update and select on their own records
|
||||
CREATE POLICY api_user_role ON api.metadata TO user_role
|
||||
USING (vessel_id = current_setting('vessel.id', true))
|
||||
WITH CHECK (vessel_id = current_setting('vessel.id', false));
|
||||
-- Allow scheduler to update and select based on the vessel.id
|
||||
CREATE POLICY api_scheduler_role ON api.metadata TO scheduler
|
||||
USING (vessel_id = current_setting('vessel.id', false))
|
||||
WITH CHECK (vessel_id = current_setting('vessel.id', false));
|
||||
-- Allow grafana to select based on email
|
||||
CREATE POLICY grafana_role ON api.metadata TO grafana
|
||||
USING (vessel_id = current_setting('vessel.id', false))
|
||||
WITH CHECK (false);
|
||||
-- Allow grafana_auth to select
|
||||
CREATE POLICY grafana_proxy_role ON api.metadata TO grafana_auth
|
||||
USING (true)
|
||||
WITH CHECK (false);
|
||||
|
||||
ALTER TABLE api.metrics ENABLE ROW LEVEL SECURITY;
|
||||
-- Administrator can see all rows and add any rows
|
||||
CREATE POLICY admin_all ON api.metrics TO current_user
|
||||
USING (true)
|
||||
WITH CHECK (true);
|
||||
-- Allow vessel_role to insert and select on their own records
|
||||
CREATE POLICY api_vessel_role ON api.metrics TO vessel_role
|
||||
USING (vessel_id = current_setting('vessel.id', false))
|
||||
WITH CHECK (true);
|
||||
-- Allow user_role to update and select on their own records
|
||||
CREATE POLICY api_user_role ON api.metrics TO user_role
|
||||
USING (vessel_id = current_setting('vessel.id', true))
|
||||
WITH CHECK (vessel_id = current_setting('vessel.id', false));
|
||||
-- Allow scheduler to update and select based on the vessel.id
|
||||
CREATE POLICY api_scheduler_role ON api.metrics TO scheduler
|
||||
USING (vessel_id = current_setting('vessel.id', false))
|
||||
WITH CHECK (vessel_id = current_setting('vessel.id', false));
|
||||
-- Allow grafana to select based on the vessel.id
|
||||
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;
|
||||
-- Create policies
|
||||
-- Administrator can see all rows and add any rows
|
||||
CREATE POLICY admin_all ON api.logbook TO current_user
|
||||
USING (true)
|
||||
WITH CHECK (true);
|
||||
-- Allow vessel_role to insert and select on their own records
|
||||
CREATE POLICY api_vessel_role ON api.logbook TO vessel_role
|
||||
USING (vessel_id = current_setting('vessel.id', false))
|
||||
WITH CHECK (true);
|
||||
-- Allow user_role to update and select on their own records
|
||||
CREATE POLICY api_user_role ON api.logbook TO user_role
|
||||
USING (vessel_id = current_setting('vessel.id', true))
|
||||
WITH CHECK (vessel_id = current_setting('vessel.id', false));
|
||||
-- Allow scheduler to update and select based on the vessel.id
|
||||
CREATE POLICY api_scheduler_role ON api.logbook TO scheduler
|
||||
USING (vessel_id = current_setting('vessel.id', false))
|
||||
WITH CHECK (vessel_id = current_setting('vessel.id', false));
|
||||
-- Allow grafana to select based on the vessel.id
|
||||
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;
|
||||
-- Administrator can see all rows and add any rows
|
||||
CREATE POLICY admin_all ON api.stays TO current_user
|
||||
USING (true)
|
||||
WITH CHECK (true);
|
||||
-- Allow vessel_role to insert and select on their own records
|
||||
CREATE POLICY api_vessel_role ON api.stays TO vessel_role
|
||||
USING (vessel_id = current_setting('vessel.id', false))
|
||||
WITH CHECK (true);
|
||||
-- Allow user_role to update and select on their own records
|
||||
CREATE POLICY api_user_role ON api.stays TO user_role
|
||||
USING (vessel_id = current_setting('vessel.id', true))
|
||||
WITH CHECK (vessel_id = current_setting('vessel.id', false));
|
||||
-- Allow scheduler to update and select based on the vessel_id
|
||||
CREATE POLICY api_scheduler_role ON api.stays TO scheduler
|
||||
USING (vessel_id = current_setting('vessel.id', false))
|
||||
WITH CHECK (vessel_id = current_setting('vessel.id', false));
|
||||
-- Allow grafana to select based on the vessel_id
|
||||
CREATE POLICY grafana_role ON api.stays 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.stays 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.moorages ENABLE ROW LEVEL SECURITY;
|
||||
-- Administrator can see all rows and add any rows
|
||||
CREATE POLICY admin_all ON api.moorages TO current_user
|
||||
USING (true)
|
||||
WITH CHECK (true);
|
||||
-- Allow vessel_role to insert and select on their own records
|
||||
CREATE POLICY api_vessel_role ON api.moorages TO vessel_role
|
||||
USING (vessel_id = current_setting('vessel.id', false))
|
||||
WITH CHECK (true);
|
||||
-- Allow user_role to update and select on their own records
|
||||
CREATE POLICY api_user_role ON api.moorages TO user_role
|
||||
USING (vessel_id = current_setting('vessel.id', true))
|
||||
WITH CHECK (vessel_id = current_setting('vessel.id', false));
|
||||
-- Allow scheduler to update and select based on the vessel_id
|
||||
CREATE POLICY api_scheduler_role ON api.moorages TO scheduler
|
||||
USING (vessel_id = current_setting('vessel.id', false))
|
||||
WITH CHECK (vessel_id = current_setting('vessel.id', false));
|
||||
-- Allow grafana to select based on the vessel_id
|
||||
CREATE POLICY grafana_role ON api.moorages 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.moorages 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 auth.vessels ENABLE ROW LEVEL SECURITY;
|
||||
-- Administrator can see all rows and add any rows
|
||||
CREATE POLICY admin_all ON auth.vessels TO current_user
|
||||
USING (true)
|
||||
WITH CHECK (true);
|
||||
-- Allow user_role to update and select on their own records
|
||||
CREATE POLICY api_user_role ON auth.vessels TO user_role
|
||||
USING (vessel_id = current_setting('vessel.id', true)
|
||||
AND owner_email = current_setting('user.email', true)
|
||||
)
|
||||
WITH CHECK (vessel_id = current_setting('vessel.id', true)
|
||||
AND owner_email = current_setting('user.email', true)
|
||||
);
|
||||
-- Allow grafana to select based on email
|
||||
CREATE POLICY grafana_role ON auth.vessels TO grafana
|
||||
USING (owner_email = current_setting('user.email', true))
|
||||
WITH CHECK (false);
|
||||
-- Allow grafana to select
|
||||
CREATE POLICY grafana_proxy_role ON auth.vessels TO grafana_auth
|
||||
USING (true)
|
||||
WITH CHECK (false);
|
||||
|
||||
-- Be sure to enable row level security on the table
|
||||
ALTER TABLE auth.accounts ENABLE ROW LEVEL SECURITY;
|
||||
-- Administrator can see all rows and add any rows
|
||||
CREATE POLICY admin_all ON auth.accounts TO current_user
|
||||
USING (true)
|
||||
WITH CHECK (true);
|
||||
-- Allow user_role to update and select on their own records
|
||||
CREATE POLICY api_user_role ON auth.accounts TO user_role
|
||||
USING (email = current_setting('user.email', true))
|
||||
WITH CHECK (email = current_setting('user.email', true));
|
||||
-- Allow scheduler see all rows and add any rows
|
||||
CREATE POLICY api_scheduler_role ON auth.accounts TO scheduler
|
||||
USING (email = current_setting('user.email', true))
|
||||
WITH CHECK (email = current_setting('user.email', true));
|
||||
-- Allow grafana_auth to select
|
||||
CREATE POLICY grafana_proxy_role ON auth.accounts TO grafana_auth
|
||||
USING (true)
|
||||
WITH CHECK (false);
|
||||
|
||||
-- Be sure to enable row level security on the table
|
||||
ALTER TABLE public.process_queue ENABLE ROW LEVEL SECURITY;
|
||||
-- Administrator can see all rows and add any rows
|
||||
CREATE POLICY admin_all ON public.process_queue TO current_user
|
||||
USING (true)
|
||||
WITH CHECK (true);
|
||||
-- Allow vessel_role to insert and select on their own records
|
||||
CREATE POLICY api_vessel_role ON public.process_queue TO vessel_role
|
||||
USING (ref_id = current_setting('user.id', true) OR ref_id = current_setting('vessel.id', true))
|
||||
WITH CHECK (true);
|
||||
-- Allow user_role to update and select on their own records
|
||||
CREATE POLICY api_user_role ON public.process_queue TO user_role
|
||||
USING (ref_id = current_setting('user.id', true) OR ref_id = current_setting('vessel.id', true))
|
||||
WITH CHECK (ref_id = current_setting('user.id', true) OR ref_id = current_setting('vessel.id', true));
|
||||
-- Allow scheduler see all rows and updates any rows
|
||||
CREATE POLICY api_scheduler_role ON public.process_queue TO scheduler
|
||||
USING (true)
|
||||
WITH CHECK (false);
|
108
initdb/03pgjwt.sql
Normal file
108
initdb/03pgjwt.sql
Normal file
@@ -0,0 +1,108 @@
|
||||
---------------------------------------------------------------------------
|
||||
--
|
||||
--\echo Use "CREATE EXTENSION pgjwt" to load this file. \quit
|
||||
-- JW implemtation for postgres
|
||||
-- https://github.com/michelp/pgjwt
|
||||
--
|
||||
|
||||
-- List current database
|
||||
select current_database();
|
||||
|
||||
-- connect to the DB
|
||||
\c signalk
|
||||
|
||||
CREATE SCHEMA IF NOT EXISTS jwt;
|
||||
COMMENT ON SCHEMA jwt IS 'jwt auth postgrest';
|
||||
|
||||
CREATE EXTENSION IF NOT EXISTS pgcrypto; -- provides cryptographic functions for PostgreSQL like HMAC
|
||||
|
||||
-- pgjwt--0.1.0--0.1.1.sql
|
||||
--
|
||||
CREATE OR REPLACE FUNCTION jwt.url_encode(data bytea) RETURNS text LANGUAGE sql AS $$
|
||||
SELECT translate(encode(data, 'base64'), E'+/=\n', '-_');
|
||||
$$ IMMUTABLE;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION jwt.url_decode(data text) RETURNS bytea LANGUAGE sql AS $$
|
||||
WITH t AS (SELECT translate(data, '-_', '+/') AS trans),
|
||||
rem AS (SELECT length(t.trans) % 4 AS remainder FROM t) -- compute padding size
|
||||
SELECT decode(
|
||||
t.trans ||
|
||||
CASE WHEN rem.remainder > 0
|
||||
THEN repeat('=', (4 - rem.remainder))
|
||||
ELSE '' END,
|
||||
'base64') FROM t, rem;
|
||||
$$ IMMUTABLE;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION jwt.algorithm_sign(signables text, secret text, algorithm text)
|
||||
RETURNS text LANGUAGE sql AS $$
|
||||
WITH
|
||||
alg AS (
|
||||
SELECT CASE
|
||||
WHEN algorithm = 'HS256' THEN 'sha256'
|
||||
WHEN algorithm = 'HS384' THEN 'sha384'
|
||||
WHEN algorithm = 'HS512' THEN 'sha512'
|
||||
ELSE '' END AS id) -- hmac throws error
|
||||
SELECT jwt.url_encode(public.hmac(signables, secret, alg.id)) FROM alg;
|
||||
$$ IMMUTABLE;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION jwt.sign(payload json, secret text, algorithm text DEFAULT 'HS256')
|
||||
RETURNS text LANGUAGE sql AS $$
|
||||
WITH
|
||||
header AS (
|
||||
SELECT jwt.url_encode(convert_to('{"alg":"' || algorithm || '","typ":"JWT"}', 'utf8')) AS data
|
||||
),
|
||||
payload AS (
|
||||
SELECT jwt.url_encode(convert_to(payload::text, 'utf8')) AS data
|
||||
),
|
||||
signables AS (
|
||||
SELECT header.data || '.' || payload.data AS data FROM header, payload
|
||||
)
|
||||
SELECT
|
||||
signables.data || '.' ||
|
||||
jwt.algorithm_sign(signables.data, secret, algorithm) FROM signables;
|
||||
$$ IMMUTABLE;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION jwt.verify(token text, secret text, algorithm text DEFAULT 'HS256')
|
||||
RETURNS table(header json, payload json, valid boolean) LANGUAGE sql AS $$
|
||||
SELECT
|
||||
convert_from(jwt.url_decode(r[1]), 'utf8')::json AS header,
|
||||
convert_from(jwt.url_decode(r[2]), 'utf8')::json AS payload,
|
||||
r[3] = jwt.algorithm_sign(r[1] || '.' || r[2], secret, algorithm) AS valid
|
||||
FROM regexp_split_to_array(token, '\.') r;
|
||||
$$ IMMUTABLE;
|
||||
|
||||
-- pgjwt--0.1.1--0.2.0.sql
|
||||
|
||||
CREATE OR REPLACE FUNCTION jwt.try_cast_double(inp text)
|
||||
RETURNS double precision AS $$
|
||||
BEGIN
|
||||
BEGIN
|
||||
RETURN inp::double precision;
|
||||
EXCEPTION
|
||||
WHEN OTHERS THEN RETURN NULL;
|
||||
END;
|
||||
END;
|
||||
$$ language plpgsql IMMUTABLE;
|
||||
|
||||
|
||||
CREATE OR REPLACE FUNCTION jwt.verify(token text, secret text, algorithm text DEFAULT 'HS256')
|
||||
RETURNS table(header json, payload json, valid boolean) LANGUAGE sql AS $$
|
||||
SELECT
|
||||
jwt.header AS header,
|
||||
jwt.payload AS payload,
|
||||
jwt.signature_ok AND tstzrange(
|
||||
to_timestamp(jwt.try_cast_double(jwt.payload->>'nbf')),
|
||||
to_timestamp(jwt.try_cast_double(jwt.payload->>'exp'))
|
||||
) @> CURRENT_TIMESTAMP AS valid
|
||||
FROM (
|
||||
SELECT
|
||||
convert_from(jwt.url_decode(r[1]), 'utf8')::json AS header,
|
||||
convert_from(jwt.url_decode(r[2]), 'utf8')::json AS payload,
|
||||
r[3] = jwt.algorithm_sign(r[1] || '.' || r[2], secret, algorithm) AS signature_ok
|
||||
FROM regexp_split_to_array(token, '\.') r
|
||||
) jwt
|
||||
$$ IMMUTABLE;
|
105
initdb/04pgcron.sql
Normal file
105
initdb/04pgcron.sql
Normal file
@@ -0,0 +1,105 @@
|
||||
---------------------------------------------------------------------------
|
||||
-- pg_cron async job
|
||||
--
|
||||
--CREATE DATABASE cron_database;
|
||||
--CREATE SCHEMA IF NOT EXISTS cron;
|
||||
--\c cron_database
|
||||
\c postgres
|
||||
|
||||
CREATE EXTENSION IF NOT EXISTS pg_cron; -- provides a simple cron-based job scheduler for PostgreSQL
|
||||
-- TRUNCATE table jobs
|
||||
--TRUNCATE TABLE cron.job CONTINUE IDENTITY RESTRICT;
|
||||
|
||||
-- Create a every 5 minutes or minute job cron_process_pre_logbook_fn ??
|
||||
SELECT cron.schedule('cron_pre_logbook', '*/5 * * * *', 'select public.cron_process_pre_logbook_fn()');
|
||||
--UPDATE cron.job SET database = 'signalk' where jobname = 'cron_pre_logbook';
|
||||
|
||||
-- Create a every 6 minutes or minute job cron_process_new_logbook_fn ??
|
||||
SELECT cron.schedule('cron_new_logbook', '*/6 * * * *', 'select public.cron_process_new_logbook_fn()');
|
||||
--UPDATE cron.job SET database = 'signalk' where jobname = 'cron_new_logbook';
|
||||
|
||||
-- Create a every 7 minute job cron_process_new_stay_fn
|
||||
SELECT cron.schedule('cron_new_stay', '*/7 * * * *', 'select public.cron_process_new_stay_fn()');
|
||||
--UPDATE cron.job SET database = 'signalk' where jobname = 'cron_new_stay';
|
||||
|
||||
-- Create a every 6 minute job cron_process_new_moorage_fn, delay from stay to give time to generate geo reverse location, eg: name
|
||||
--SELECT cron.schedule('cron_new_moorage', '*/7 * * * *', 'select public.cron_process_new_moorage_fn()');
|
||||
--UPDATE cron.job SET database = 'signalk' where jobname = 'cron_new_moorage';
|
||||
|
||||
-- Create a every 11 minute job cron_process_monitor_offline_fn
|
||||
SELECT cron.schedule('cron_monitor_offline', '*/11 * * * *', 'select public.cron_process_monitor_offline_fn()');
|
||||
--UPDATE cron.job SET database = 'signalk' where jobname = 'cron_monitor_offline';
|
||||
|
||||
-- Create a every 10 minute job cron_process_monitor_online_fn
|
||||
SELECT cron.schedule('cron_monitor_online', '*/10 * * * *', 'select public.cron_process_monitor_online_fn()');
|
||||
--UPDATE cron.job SET database = 'signalk' where jobname = 'cron_monitor_online';
|
||||
|
||||
-- Create a every 5 minute job cron_process_new_account_fn
|
||||
--SELECT cron.schedule('cron_new_account', '*/5 * * * *', 'select public.cron_process_new_account_fn()');
|
||||
--UPDATE cron.job SET database = 'signalk' where jobname = 'cron_new_account';
|
||||
|
||||
-- Create a every 5 minute job cron_process_new_vessel_fn
|
||||
--SELECT cron.schedule('cron_new_vessel', '*/5 * * * *', 'select public.cron_process_new_vessel_fn()');
|
||||
--UPDATE cron.job SET database = 'signalk' where jobname = 'cron_new_vessel';
|
||||
|
||||
-- Create a every 6 minute job cron_process_new_account_otp_validation_queue_fn, delay from cron_new_account
|
||||
--SELECT cron.schedule('cron_new_account_otp', '*/6 * * * *', 'select public.cron_process_new_account_otp_validation_fn()');
|
||||
--UPDATE cron.job SET database = 'signalk' where jobname = 'cron_new_account_otp';
|
||||
|
||||
-- Create a every 5 minute job cron_process_grafana_fn
|
||||
SELECT cron.schedule('cron_grafana', '*/5 * * * *', 'select public.cron_process_grafana_fn()');
|
||||
|
||||
-- Create a every 5 minute job cron_process_windy_fn
|
||||
SELECT cron.schedule('cron_windy', '*/5 * * * *', 'select public.cron_windy_fn()');
|
||||
|
||||
-- Notification
|
||||
-- Create a every 1 minute job cron_process_new_notification_queue_fn, new_account, new_vessel, _new_account_otp
|
||||
SELECT cron.schedule('cron_new_notification', '*/1 * * * *', 'select public.cron_process_new_notification_fn()');
|
||||
--UPDATE cron.job SET database = 'signalk' where jobname = 'cron_new_notification';
|
||||
|
||||
-- Maintenance
|
||||
-- Vacuum database schema api at "At 01:31 on Sunday."
|
||||
SELECT cron.schedule('cron_vacuum_api', '31 1 * * 0', 'VACUUM (FULL, VERBOSE, ANALYZE, INDEX_CLEANUP) api.logbook,api.stays,api.moorages,api.metadata,api.metrics;');
|
||||
-- Vacuum database schema auth at "At 01:01 on Sunday."
|
||||
SELECT cron.schedule('cron_vacuum_auth', '1 1 * * 0', 'VACUUM (FULL, VERBOSE, ANALYZE, INDEX_CLEANUP) auth.accounts,auth.vessels,auth.otp;');
|
||||
-- Remove old jobs log at "At 02:02 on Sunday."
|
||||
SELECT cron.schedule('job_run_details_cleanup', '2 2 * * 0', 'select public.job_run_details_cleanup_fn()');
|
||||
-- Rebuilding indexes schema api at "first day of each month at 23:15."
|
||||
SELECT cron.schedule('cron_reindex_api', '15 23 1 * *', 'REINDEX TABLE CONCURRENTLY api.logbook; REINDEX TABLE CONCURRENTLY api.stays; REINDEX TABLE CONCURRENTLY api.moorages; REINDEX TABLE CONCURRENTLY api.metadata;');
|
||||
-- Rebuilding indexes schema auth at "first day of each month at 23:01."
|
||||
SELECT cron.schedule('cron_reindex_auth', '1 23 1 * *', 'REINDEX TABLE CONCURRENTLY auth.accounts; REINDEX TABLE CONCURRENTLY auth.vessels; REINDEX TABLE CONCURRENTLY auth.otp;');
|
||||
-- Any other maintenance require?
|
||||
|
||||
-- OTP
|
||||
-- Create a every 15 minute job cron_prune_otp_fn
|
||||
SELECT cron.schedule('cron_prune_otp', '*/15 * * * *', 'select public.cron_prune_otp_fn()');
|
||||
|
||||
-- Alerts
|
||||
-- Create a every 11 minute job cron_alerts_fn
|
||||
SELECT cron.schedule('cron_alerts', '*/11 * * * *', 'select public.cron_alerts_fn()');
|
||||
|
||||
-- Notifications/Reminders of no vessel & no metadata & no activity
|
||||
-- At 08:05 on Sunday.
|
||||
-- At 08:05 on every 4th day-of-month if it's on Sunday.
|
||||
SELECT cron.schedule('cron_no_vessel', '5 8 */4 * 0', 'select public.cron_no_vessel_fn()');
|
||||
SELECT cron.schedule('cron_no_metadata', '5 8 */4 * 0', 'select public.cron_no_metadata_fn()');
|
||||
SELECT cron.schedule('cron_no_activity', '5 8 */4 * 0', 'select public.cron_no_activity_fn()');
|
||||
|
||||
-- Cron job settings
|
||||
UPDATE cron.job SET database = 'signalk';
|
||||
UPDATE cron.job SET username = current_user; -- TODO update to scheduler, pending process_queue update
|
||||
--UPDATE cron.job SET username = 'username' where jobname = 'cron_vacuum'; -- TODO Update to superuser for vacuum permissions
|
||||
UPDATE cron.job SET nodename = '/var/run/postgresql/'; -- VS default localhost ??
|
||||
UPDATE cron.job SET database = 'postgres' WHERE jobname = 'job_run_details_cleanup';
|
||||
-- check job lists
|
||||
SELECT * FROM cron.job;
|
||||
-- unschedule by job id
|
||||
--SELECT cron.unschedule(1);
|
||||
-- unschedule by job name
|
||||
--SELECT cron.unschedule('cron_new_logbook');
|
||||
-- TRUNCATE TABLE cron.job_run_details
|
||||
--TRUNCATE TABLE cron.job_run_details CONTINUE IDENTITY RESTRICT;
|
||||
-- check job log
|
||||
SELECT * FROM cron.job_run_details ORDER BY end_time DESC;
|
||||
-- DEBUG Disable all
|
||||
UPDATE cron.job SET active = False;
|
76
initdb/07naturalearthdata.sql
Normal file
76
initdb/07naturalearthdata.sql
Normal file
@@ -0,0 +1,76 @@
|
||||
---------------------------------------------------------------------------
|
||||
-- https://www.naturalearthdata.com
|
||||
--
|
||||
-- https://naciscdn.org/naturalearth/10m/physical/ne_10m_geography_marine_polys.zip
|
||||
--
|
||||
-- https://github.com/nvkelso/natural-earth-vector/raw/master/10m_physical/ne_10m_geography_marine_polys.shp
|
||||
--
|
||||
|
||||
-- Import from shapefile
|
||||
-- # shp2pgsql ne_10m_geography_marine_polys.shp public.ne_10m_geography_marine_polys | psql -U ${POSTGRES_USER} signalk
|
||||
--
|
||||
-- PostgSail Customization, add tropics and alaska area.
|
||||
|
||||
-- List current database
|
||||
select current_database();
|
||||
|
||||
-- connect to the DB
|
||||
\c signalk
|
||||
|
||||
CREATE TABLE public.ne_10m_geography_marine_polys (
|
||||
gid INT GENERATED ALWAYS AS IDENTITY NOT NULL,
|
||||
featurecla TEXT NULL,
|
||||
"name" TEXT NULL,
|
||||
namealt TEXT NULL,
|
||||
changed TEXT NULL,
|
||||
note TEXT NULL,
|
||||
name_fr TEXT NULL,
|
||||
min_label float8 NULL,
|
||||
max_label float8 NULL,
|
||||
scalerank int2 NULL,
|
||||
"label" TEXT NULL,
|
||||
wikidataid TEXT NULL,
|
||||
name_ar TEXT NULL,
|
||||
name_bn TEXT NULL,
|
||||
name_de TEXT NULL,
|
||||
name_en TEXT NULL,
|
||||
name_es TEXT NULL,
|
||||
name_el TEXT NULL,
|
||||
name_hi TEXT NULL,
|
||||
name_hu TEXT NULL,
|
||||
name_id TEXT NULL,
|
||||
name_it TEXT NULL,
|
||||
name_ja TEXT NULL,
|
||||
name_ko TEXT NULL,
|
||||
name_nl TEXT NULL,
|
||||
name_pl TEXT NULL,
|
||||
name_pt TEXT NULL,
|
||||
name_ru TEXT NULL,
|
||||
name_sv TEXT NULL,
|
||||
name_tr TEXT NULL,
|
||||
name_vi TEXT NULL,
|
||||
name_zh TEXT NULL,
|
||||
ne_id int8 NULL,
|
||||
name_fa TEXT NULL,
|
||||
name_he TEXT NULL,
|
||||
name_uk TEXT NULL,
|
||||
name_ur TEXT NULL,
|
||||
name_zht TEXT NULL,
|
||||
geom geometry(multipolygon,4326) NULL,
|
||||
CONSTRAINT ne_10m_geography_marine_polys_pkey PRIMARY KEY (gid)
|
||||
);
|
||||
-- Add GIST index
|
||||
CREATE INDEX ne_10m_geography_marine_polys_geom_idx
|
||||
ON public.ne_10m_geography_marine_polys
|
||||
USING GIST (geom);
|
||||
|
||||
-- Description
|
||||
COMMENT ON TABLE
|
||||
public.ne_10m_geography_marine_polys
|
||||
IS 'imperfect but light weight geographic marine areas from https://www.naturalearthdata.com';
|
||||
|
||||
-- Import data
|
||||
COPY public.ne_10m_geography_marine_polys(gid,featurecla,"name",namealt,changed,note,name_fr,min_label,max_label,scalerank,"label",wikidataid,name_ar,name_bn,name_de,name_en,name_es,name_el,name_hi,name_hu,name_id,name_it,name_ja,name_ko,name_nl,name_pl,name_pt,name_ru,name_sv,name_tr,name_vi,name_zh,ne_id,name_fa,name_he,name_uk,name_ur,name_zht,geom)
|
||||
FROM '/docker-entrypoint-initdb.d/ne_10m_geography_marine_polys.csv'
|
||||
DELIMITER ','
|
||||
CSV HEADER;
|
457
initdb/99_migrations_202401.sql
Normal file
457
initdb/99_migrations_202401.sql
Normal file
@@ -0,0 +1,457 @@
|
||||
---------------------------------------------------------------------------
|
||||
-- Copyright 2021-2024 Francois Lacroix <xbgmsharp@gmail.com>
|
||||
-- This file is part of PostgSail which is released under Apache License, Version 2.0 (the "License").
|
||||
-- See file LICENSE or go to http://www.apache.org/licenses/LICENSE-2.0 for full license details.
|
||||
--
|
||||
-- Migration January 2024
|
||||
--
|
||||
-- List current database
|
||||
select current_database();
|
||||
|
||||
-- connect to the DB
|
||||
\c signalk
|
||||
|
||||
\echo 'Force timezone, just in case'
|
||||
set timezone to 'UTC';
|
||||
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_process_new_moorage_fn
|
||||
IS 'Deprecated, init by pg_cron to check for new moorage pending update, if so perform process_moorage_queue_fn';
|
||||
|
||||
DROP FUNCTION IF EXISTS reverse_geoip_py_fn;
|
||||
CREATE OR REPLACE FUNCTION reverse_geoip_py_fn(IN _ip TEXT) RETURNS JSONB
|
||||
AS $reverse_geoip_py$
|
||||
"""
|
||||
Return ipapi.co ip details
|
||||
"""
|
||||
import requests
|
||||
import json
|
||||
|
||||
# requests
|
||||
url = f'https://ipapi.co/{_ip}/json/'
|
||||
r = requests.get(url)
|
||||
#print(r.text)
|
||||
#plpy.notice('IP [{}] [{}]'.format(_ip, r.status_code))
|
||||
if r.status_code == 200:
|
||||
#plpy.notice('Got [{}] [{}]'.format(r.text, r.status_code))
|
||||
return r.json()
|
||||
else:
|
||||
plpy.error('Failed to get ip details')
|
||||
return {}
|
||||
$reverse_geoip_py$ IMMUTABLE strict TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.reverse_geoip_py_fn
|
||||
IS 'Retrieve reverse geo IP location via ipapi.co using plpython3u';
|
||||
|
||||
DROP FUNCTION IF EXISTS overpass_py_fn;
|
||||
CREATE OR REPLACE FUNCTION overpass_py_fn(IN lon NUMERIC, IN lat NUMERIC,
|
||||
OUT geo JSONB) RETURNS JSONB
|
||||
AS $overpass_py$
|
||||
"""
|
||||
Return https://overpass-turbo.eu seamark details within 400m
|
||||
https://overpass-turbo.eu/s/1EaG
|
||||
https://wiki.openstreetmap.org/wiki/Key:seamark:type
|
||||
"""
|
||||
import requests
|
||||
import json
|
||||
import urllib.parse
|
||||
|
||||
headers = {'User-Agent': 'PostgSail', 'From': 'xbgmsharp@gmail.com'}
|
||||
payload = """
|
||||
[out:json][timeout:20];
|
||||
is_in({0},{1})->.result_areas;
|
||||
(
|
||||
area.result_areas["seamark:type"~"(mooring|harbour)"][~"^seamark:.*:category$"~"."];
|
||||
area.result_areas["leisure"="marina"][~"name"~"."];
|
||||
);
|
||||
out tags;
|
||||
nwr(around:400.0,{0},{1})->.all;
|
||||
(
|
||||
nwr.all["seamark:type"~"(mooring|harbour)"][~"^seamark:.*:category$"~"."];
|
||||
nwr.all["seamark:type"~"(anchorage|anchor_berth|berth)"];
|
||||
nwr.all["leisure"="marina"];
|
||||
nwr.all["natural"~"(bay|beach)"];
|
||||
);
|
||||
out tags;
|
||||
""".format(lat, lon)
|
||||
data = urllib.parse.quote(payload, safe="");
|
||||
url = f'https://overpass-api.de/api/interpreter?data={data}'.format(data)
|
||||
r = requests.get(url, headers)
|
||||
#print(r.text)
|
||||
#plpy.notice(url)
|
||||
plpy.notice('overpass-api coord lon[{}] lat[{}] [{}]'.format(lon, lat, r.status_code))
|
||||
if r.status_code == 200 and "elements" in r.json():
|
||||
r_dict = r.json()
|
||||
plpy.notice('overpass-api Got [{}]'.format(r_dict["elements"]))
|
||||
if r_dict["elements"]:
|
||||
if "tags" in r_dict["elements"][0] and r_dict["elements"][0]["tags"]:
|
||||
return r_dict["elements"][0]["tags"]; # return the first element
|
||||
return {}
|
||||
else:
|
||||
plpy.notice('overpass-api Failed to get overpass-api details')
|
||||
return {}
|
||||
$overpass_py$ IMMUTABLE strict TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.overpass_py_fn
|
||||
IS 'Return https://overpass-turbo.eu seamark details within 400m using plpython3u';
|
||||
|
||||
CREATE OR REPLACE FUNCTION get_app_settings_fn(OUT app_settings jsonb)
|
||||
RETURNS jsonb
|
||||
AS $get_app_settings$
|
||||
DECLARE
|
||||
BEGIN
|
||||
SELECT
|
||||
jsonb_object_agg(name, value) INTO app_settings
|
||||
FROM
|
||||
public.app_settings
|
||||
WHERE
|
||||
name LIKE 'app.email%'
|
||||
OR name LIKE 'app.pushover%'
|
||||
OR name LIKE 'app.url'
|
||||
OR name LIKE 'app.telegram%'
|
||||
OR name LIKE 'app.grafana_admin_uri'
|
||||
OR name LIKE 'app.keycloak_uri';
|
||||
END;
|
||||
$get_app_settings$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION keycloak_auth_py_fn(IN _v_id TEXT,
|
||||
IN _user JSONB, IN app JSONB) RETURNS JSONB
|
||||
AS $keycloak_auth_py$
|
||||
"""
|
||||
Addkeycloak user
|
||||
"""
|
||||
import requests
|
||||
import json
|
||||
import urllib.parse
|
||||
|
||||
safe_uri = host = user = pwd = None
|
||||
if 'app.keycloak_uri' in app and app['app.keycloak_uri']:
|
||||
#safe_uri = urllib.parse.quote(app['app.keycloak_uri'], safe=':/?&=')
|
||||
_ = urllib.parse.urlparse(app['app.keycloak_uri'])
|
||||
host = _.netloc.split('@')[-1]
|
||||
user = _.netloc.split(':')[0]
|
||||
pwd = _.netloc.split(':')[1].split('@')[0]
|
||||
else:
|
||||
plpy.error('Error no keycloak_uri defined, check app settings')
|
||||
return none
|
||||
|
||||
if not host or not user or not pwd:
|
||||
plpy.error('Error parsing keycloak_uri, check app settings')
|
||||
return None
|
||||
|
||||
if not 'email' in _user and _user['email']:
|
||||
plpy.error('Error parsing user email, check user settings')
|
||||
return none
|
||||
|
||||
if not _v_id:
|
||||
plpy.error('Error parsing vessel_id')
|
||||
return none
|
||||
|
||||
_headers = {'User-Agent': 'PostgSail', 'From': 'xbgmsharp@gmail.com'}
|
||||
_payload = {'client_id':'admin-cli','grant_type':'password','username':user,'password':pwd}
|
||||
url = f'{_.scheme}://{host}/realms/master/protocol/openid-connect/token'.format(_.scheme, host)
|
||||
r = requests.post(url, headers=_headers, data=_payload, timeout=(5, 60))
|
||||
#print(r.text)
|
||||
#plpy.notice(url)
|
||||
if r.status_code == 200 and 'access_token' in r.json():
|
||||
response = r.json()
|
||||
plpy.notice(response)
|
||||
_headers['Authorization'] = 'Bearer '+ response['access_token']
|
||||
_headers['Content-Type'] = 'application/json'
|
||||
url = f'{_.scheme}://{host}/admin/realms/postgsail/users'.format(_.scheme, host)
|
||||
_payload = {
|
||||
"enabled": "true",
|
||||
"email": _user['email'],
|
||||
"firstName": _user['recipient'],
|
||||
"attributes": {"vessel_id": _v_id},
|
||||
"emailVerified": True,
|
||||
"requiredActions":["UPDATE_PROFILE", "UPDATE_PASSWORD"]
|
||||
}
|
||||
plpy.notice(_payload)
|
||||
data = json.dumps(_payload)
|
||||
r = requests.post(url, headers=_headers, data=data, timeout=(5, 60))
|
||||
if r.status_code != 201:
|
||||
#print("Error creating user: {status}".format(status=r.status_code))
|
||||
plpy.error(f'Error creating user: {user} {status}'.format(user=_payload['email'], status=r.status_code))
|
||||
return None
|
||||
else:
|
||||
#print("Created user : {u}]".format(u=_payload['email']))
|
||||
plpy.notice('Created user : {u} {t}, {l}'.format(u=_payload['email'], t=r.text, l=r.headers['location']))
|
||||
user_url = "{user_url}/execute-actions-email".format(user_url=r.headers['location'])
|
||||
_payload = ["UPDATE_PASSWORD"]
|
||||
plpy.notice(_payload)
|
||||
data = json.dumps(_payload)
|
||||
r = requests.put(user_url, headers=_headers, data=data, timeout=(5, 60))
|
||||
if r.status_code != 204:
|
||||
plpy.error('Error execute-actions-email: {u} {s}'.format(u=_user['email'], s=r.status_code))
|
||||
else:
|
||||
plpy.notice('execute-actions-email: {u} {s}'.format(u=_user['email'], s=r.status_code))
|
||||
return None
|
||||
else:
|
||||
plpy.error(f'Error getting admin access_token: {status}'.format(status=r.status_code))
|
||||
return None
|
||||
$keycloak_auth_py$ strict TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.keycloak_auth_py_fn
|
||||
IS 'Return set oauth user attribute into keycloak using plpython3u';
|
||||
|
||||
CREATE OR REPLACE FUNCTION keycloak_py_fn(IN user_id TEXT, IN vessel_id TEXT,
|
||||
IN app JSONB) RETURNS JSONB
|
||||
AS $keycloak_py$
|
||||
"""
|
||||
Add vessel_id user attribute to keycloak user {user_id}
|
||||
"""
|
||||
import requests
|
||||
import json
|
||||
import urllib.parse
|
||||
|
||||
safe_uri = host = user = pwd = None
|
||||
if 'app.keycloak_uri' in app and app['app.keycloak_uri']:
|
||||
#safe_uri = urllib.parse.quote(app['app.keycloak_uri'], safe=':/?&=')
|
||||
_ = urllib.parse.urlparse(app['app.keycloak_uri'])
|
||||
host = _.netloc.split('@')[-1]
|
||||
user = _.netloc.split(':')[0]
|
||||
pwd = _.netloc.split(':')[1].split('@')[0]
|
||||
else:
|
||||
plpy.error('Error no keycloak_uri defined, check app settings')
|
||||
return None
|
||||
|
||||
if not host or not user or not pwd:
|
||||
plpy.error('Error parsing keycloak_uri, check app settings')
|
||||
return None
|
||||
|
||||
_headers = {'User-Agent': 'PostgSail', 'From': 'xbgmsharp@gmail.com'}
|
||||
_payload = {'client_id':'admin-cli','grant_type':'password','username':user,'password':pwd}
|
||||
url = f'{_.scheme}://{host}/realms/master/protocol/openid-connect/token'.format(_.scheme, host)
|
||||
r = requests.post(url, headers=_headers, data=_payload, timeout=(5, 60))
|
||||
#print(r.text)
|
||||
#plpy.notice(url)
|
||||
if r.status_code == 200 and 'access_token' in r.json():
|
||||
response = r.json()
|
||||
plpy.notice(response)
|
||||
_headers['Authorization'] = 'Bearer '+ response['access_token']
|
||||
_headers['Content-Type'] = 'application/json'
|
||||
_payload = { 'attributes': {'vessel_id': vessel_id} }
|
||||
url = f'{keycloak_uri}/admin/realms/postgsail/users/{user_id}'.format(keycloak_uri,user_id)
|
||||
#plpy.notice(url)
|
||||
#plpy.notice(_payload)
|
||||
data = json.dumps(_payload)
|
||||
r = requests.put(url, headers=_headers, data=data, timeout=(5, 60))
|
||||
if r.status_code != 204:
|
||||
plpy.notice("Error updating user: {status} [{text}]".format(
|
||||
status=r.status_code, text=r.text))
|
||||
return None
|
||||
else:
|
||||
plpy.notice("Updated user : {user} [{text}]".format(user=user_id, text=r.text))
|
||||
else:
|
||||
plpy.notice(f'Error getting admin access_token: {status} [{text}]'.format(
|
||||
status=r.status_code, text=r.text))
|
||||
return None
|
||||
$keycloak_py$ strict TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
||||
|
||||
UPDATE public.email_templates
|
||||
SET pushover_message='Congratulations!
|
||||
You unlocked Grafana dashboard.
|
||||
See more details at https://app.openplotter.cloud
|
||||
',email_content='Hello __RECIPIENT__,
|
||||
Congratulations! You unlocked Grafana dashboard.
|
||||
See more details at https://app.openplotter.cloud
|
||||
Happy sailing!
|
||||
Francois'
|
||||
WHERE "name"='grafana';
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.cron_process_grafana_fn()
|
||||
RETURNS void
|
||||
LANGUAGE plpgsql
|
||||
AS $function$
|
||||
DECLARE
|
||||
process_rec record;
|
||||
data_rec record;
|
||||
app_settings jsonb;
|
||||
user_settings jsonb;
|
||||
BEGIN
|
||||
-- We run grafana provisioning only after the first received vessel metadata
|
||||
-- Check for new vessel metadata pending grafana provisioning
|
||||
RAISE NOTICE 'cron_process_grafana_fn';
|
||||
FOR process_rec in
|
||||
SELECT * from process_queue
|
||||
where channel = 'grafana' and processed is null
|
||||
order by stored asc
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_process_grafana_fn [%]', process_rec.payload;
|
||||
-- Gather url from app settings
|
||||
app_settings := get_app_settings_fn();
|
||||
-- Get vessel details base on metadata id
|
||||
SELECT * INTO data_rec
|
||||
FROM api.metadata m, auth.vessels v
|
||||
WHERE m.id = process_rec.payload::INTEGER
|
||||
AND m.vessel_id = v.vessel_id;
|
||||
-- as we got data from the vessel we can do the grafana provisioning.
|
||||
PERFORM grafana_py_fn(data_rec.name, data_rec.vessel_id, data_rec.owner_email, app_settings);
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(data_rec.vessel_id::TEXT);
|
||||
RAISE DEBUG '-> DEBUG cron_process_grafana_fn get_user_settings_from_vesselid_fn [%]', user_settings;
|
||||
-- add user in keycloak
|
||||
PERFORM keycloak_auth_py_fn(data_rec.vessel_id, user_settings, app_settings);
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('grafana'::TEXT, user_settings::JSONB);
|
||||
-- update process_queue entry as processed
|
||||
UPDATE process_queue
|
||||
SET
|
||||
processed = NOW()
|
||||
WHERE id = process_rec.id;
|
||||
RAISE NOTICE '-> cron_process_grafana_fn updated process_queue table [%]', process_rec.id;
|
||||
END LOOP;
|
||||
END;
|
||||
$function$
|
||||
;
|
||||
COMMENT ON FUNCTION public.cron_process_grafana_fn() IS 'init by pg_cron to check for new vessel pending grafana provisioning, if so perform grafana_py_fn';
|
||||
|
||||
-- DROP FUNCTION public.grafana_py_fn(text, text, text, jsonb);
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.grafana_py_fn(_v_name text, _v_id text, _u_email text, app jsonb)
|
||||
RETURNS void
|
||||
TRANSFORM FOR TYPE jsonb
|
||||
LANGUAGE plpython3u
|
||||
AS $function$
|
||||
"""
|
||||
https://grafana.com/docs/grafana/latest/developers/http_api/
|
||||
Create organization base on vessel name
|
||||
Create user base on user email
|
||||
Add user to organization
|
||||
Add data_source to organization
|
||||
Add dashboard to organization
|
||||
Update organization preferences
|
||||
"""
|
||||
import requests
|
||||
import json
|
||||
import re
|
||||
|
||||
grafana_uri = None
|
||||
if 'app.grafana_admin_uri' in app and app['app.grafana_admin_uri']:
|
||||
grafana_uri = app['app.grafana_admin_uri']
|
||||
else:
|
||||
plpy.error('Error no grafana_admin_uri defined, check app settings')
|
||||
return None
|
||||
|
||||
b_name = None
|
||||
if not _v_name:
|
||||
b_name = _v_id
|
||||
else:
|
||||
b_name = _v_name
|
||||
|
||||
# add vessel org
|
||||
headers = {'User-Agent': 'PostgSail', 'From': 'xbgmsharp@gmail.com',
|
||||
'Accept': 'application/json', 'Content-Type': 'application/json'}
|
||||
path = 'api/orgs'
|
||||
url = f'{grafana_uri}/{path}'.format(grafana_uri,path)
|
||||
data_dict = {'name':b_name}
|
||||
data = json.dumps(data_dict)
|
||||
r = requests.post(url, data=data, headers=headers)
|
||||
#print(r.text)
|
||||
plpy.notice(r.json())
|
||||
if r.status_code == 200 and "orgId" in r.json():
|
||||
org_id = r.json()['orgId']
|
||||
else:
|
||||
plpy.error('Error grafana add vessel org %', r.json())
|
||||
return none
|
||||
|
||||
# add user to vessel org
|
||||
path = 'api/admin/users'
|
||||
url = f'{grafana_uri}/{path}'.format(grafana_uri,path)
|
||||
data_dict = {'orgId':org_id, 'email':_u_email, 'password':'asupersecretpassword'}
|
||||
data = json.dumps(data_dict)
|
||||
r = requests.post(url, data=data, headers=headers)
|
||||
#print(r.text)
|
||||
plpy.notice(r.json())
|
||||
if r.status_code == 200 and "id" in r.json():
|
||||
user_id = r.json()['id']
|
||||
else:
|
||||
plpy.error('Error grafana add user to vessel org')
|
||||
return
|
||||
|
||||
# read data_source
|
||||
path = 'api/datasources/1'
|
||||
url = f'{grafana_uri}/{path}'.format(grafana_uri,path)
|
||||
r = requests.get(url, headers=headers)
|
||||
#print(r.text)
|
||||
plpy.notice(r.json())
|
||||
data_source = r.json()
|
||||
data_source['id'] = 0
|
||||
data_source['orgId'] = org_id
|
||||
data_source['uid'] = "ds_" + _v_id
|
||||
data_source['name'] = "ds_" + _v_id
|
||||
data_source['secureJsonData'] = {}
|
||||
data_source['secureJsonData']['password'] = 'mysecretpassword'
|
||||
data_source['readOnly'] = True
|
||||
del data_source['secureJsonFields']
|
||||
|
||||
# add data_source to vessel org
|
||||
path = 'api/datasources'
|
||||
url = f'{grafana_uri}/{path}'.format(grafana_uri,path)
|
||||
data = json.dumps(data_source)
|
||||
headers['X-Grafana-Org-Id'] = str(org_id)
|
||||
r = requests.post(url, data=data, headers=headers)
|
||||
plpy.notice(r.json())
|
||||
del headers['X-Grafana-Org-Id']
|
||||
if r.status_code != 200 and "id" not in r.json():
|
||||
plpy.error('Error grafana add data_source to vessel org')
|
||||
return
|
||||
|
||||
dashboards_tpl = [ 'pgsail_tpl_electrical', 'pgsail_tpl_logbook', 'pgsail_tpl_monitor', 'pgsail_tpl_rpi', 'pgsail_tpl_solar', 'pgsail_tpl_weather', 'pgsail_tpl_home']
|
||||
for dashboard in dashboards_tpl:
|
||||
# read dashboard template by uid
|
||||
path = 'api/dashboards/uid'
|
||||
url = f'{grafana_uri}/{path}/{dashboard}'.format(grafana_uri,path,dashboard)
|
||||
if 'X-Grafana-Org-Id' in headers:
|
||||
del headers['X-Grafana-Org-Id']
|
||||
r = requests.get(url, headers=headers)
|
||||
plpy.notice(r.json())
|
||||
if r.status_code != 200 and "id" not in r.json():
|
||||
plpy.error('Error grafana read dashboard template')
|
||||
return
|
||||
new_dashboard = r.json()
|
||||
del new_dashboard['meta']
|
||||
new_dashboard['dashboard']['version'] = 0
|
||||
new_dashboard['dashboard']['id'] = 0
|
||||
new_uid = re.sub(r'pgsail_tpl_(.*)', r'postgsail_\1', new_dashboard['dashboard']['uid'])
|
||||
new_dashboard['dashboard']['uid'] = f'{new_uid}_{_v_id}'.format(new_uid,_v_id)
|
||||
# add dashboard to vessel org
|
||||
path = 'api/dashboards/db'
|
||||
url = f'{grafana_uri}/{path}'.format(grafana_uri,path)
|
||||
data = json.dumps(new_dashboard)
|
||||
new_data = data.replace('PCC52D03280B7034C', data_source['uid'])
|
||||
headers['X-Grafana-Org-Id'] = str(org_id)
|
||||
r = requests.post(url, data=new_data, headers=headers)
|
||||
plpy.notice(r.json())
|
||||
if r.status_code != 200 and "id" not in r.json():
|
||||
plpy.error('Error grafana add dashboard to vessel org')
|
||||
return
|
||||
|
||||
# Update Org Prefs
|
||||
path = 'api/org/preferences'
|
||||
url = f'{grafana_uri}/{path}'.format(grafana_uri,path)
|
||||
home_dashboard = {}
|
||||
home_dashboard['timezone'] = 'utc'
|
||||
home_dashboard['homeDashboardUID'] = f'postgsail_home_{_v_id}'.format(_v_id)
|
||||
data = json.dumps(home_dashboard)
|
||||
headers['X-Grafana-Org-Id'] = str(org_id)
|
||||
r = requests.patch(url, data=data, headers=headers)
|
||||
plpy.notice(r.json())
|
||||
if r.status_code != 200:
|
||||
plpy.error('Error grafana update org preferences')
|
||||
return
|
||||
|
||||
plpy.notice('Done')
|
||||
$function$
|
||||
;
|
||||
|
||||
COMMENT ON FUNCTION public.grafana_py_fn(text, text, text, jsonb) IS 'Grafana Organization,User,data_source,dashboards provisioning via HTTP API using plpython3u';
|
||||
|
||||
UPDATE public.app_settings
|
||||
SET value='0.6.1'
|
||||
WHERE "name"='app.version';
|
855
initdb/99_migrations_202402.sql
Normal file
855
initdb/99_migrations_202402.sql
Normal file
@@ -0,0 +1,855 @@
|
||||
---------------------------------------------------------------------------
|
||||
-- Copyright 2021-2024 Francois Lacroix <xbgmsharp@gmail.com>
|
||||
-- This file is part of PostgSail which is released under Apache License, Version 2.0 (the "License").
|
||||
-- See file LICENSE or go to http://www.apache.org/licenses/LICENSE-2.0 for full license details.
|
||||
--
|
||||
-- Migration February 2024
|
||||
--
|
||||
-- List current database
|
||||
select current_database();
|
||||
|
||||
-- connect to the DB
|
||||
\c signalk
|
||||
|
||||
\echo 'Force timezone, just in case'
|
||||
set timezone to 'UTC';
|
||||
|
||||
-- Update email_templates
|
||||
--INSERT INTO public.email_templates ("name",email_subject,email_content,pushover_title,pushover_message)
|
||||
-- VALUES ('windy','PostgSail Windy Weather station',E'Hello __RECIPIENT__,\nCongratulations! Your boat is now a Windy Weather station.\nSee more details at __APP_URL__/windy\nHappy sailing!\nFrancois','PostgSail Windy!',E'Congratulations!\nYour boat is now a Windy Weather station.\nSee more details at __APP_URL__/windy\n');
|
||||
--INSERT INTO public.email_templates ("name",email_subject,email_content,pushover_title,pushover_message)
|
||||
--VALUES ('alert','PostgSail Alert',E'Hello __RECIPIENT__,\nWe detected an alert __ALERT__.\nSee more details at __APP_URL__\nStay safe.\nFrancois','PostgSail Alert!',E'Congratulations!\nWe detected an alert __ALERT__.\n');
|
||||
|
||||
INSERT INTO public.email_templates ("name",email_subject,email_content,pushover_title,pushover_message)
|
||||
VALUES ('windy_error','PostgSail Windy Weather station Error',E'Hello __RECIPIENT__,\nSorry!We could not convert your boat into a Windy Personal Weather Station due to missing data (temp or wind).\nWindy Personal Weather Station is now disable.','PostgSail Windy error!',E'Sorry!\nWe could not convert your boat into a Windy Personal Weather Station.');
|
||||
|
||||
-- Update app_settings
|
||||
CREATE OR REPLACE FUNCTION public.get_app_settings_fn(OUT app_settings jsonb)
|
||||
RETURNS jsonb
|
||||
AS $get_app_settings$
|
||||
DECLARE
|
||||
BEGIN
|
||||
SELECT
|
||||
jsonb_object_agg(name, value) INTO app_settings
|
||||
FROM
|
||||
public.app_settings
|
||||
WHERE
|
||||
name LIKE 'app.email%'
|
||||
OR name LIKE 'app.pushover%'
|
||||
OR name LIKE 'app.url'
|
||||
OR name LIKE 'app.telegram%'
|
||||
OR name LIKE 'app.grafana_admin_uri'
|
||||
OR name LIKE 'app.keycloak_uri'
|
||||
OR name LIKE 'app.windy_apikey';
|
||||
END;
|
||||
$get_app_settings$
|
||||
LANGUAGE plpgsql;
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.get_user_settings_from_vesselid_fn(
|
||||
IN vesselid TEXT,
|
||||
OUT user_settings JSONB
|
||||
) RETURNS JSONB
|
||||
AS $get_user_settings_from_vesselid$
|
||||
DECLARE
|
||||
BEGIN
|
||||
-- If vessel_id is not NULL
|
||||
IF vesselid IS NULL OR vesselid = '' THEN
|
||||
RAISE WARNING '-> get_user_settings_from_vesselid_fn invalid input %', vesselid;
|
||||
END IF;
|
||||
SELECT
|
||||
json_build_object(
|
||||
'boat' , v.name,
|
||||
'recipient', a.first,
|
||||
'email', v.owner_email,
|
||||
'settings', a.preferences
|
||||
) INTO user_settings
|
||||
FROM auth.accounts a, auth.vessels v, api.metadata m
|
||||
WHERE m.vessel_id = v.vessel_id
|
||||
AND m.vessel_id = vesselid
|
||||
AND a.email = v.owner_email;
|
||||
PERFORM set_config('user.email', user_settings->>'email'::TEXT, false);
|
||||
PERFORM set_config('user.recipient', user_settings->>'recipient'::TEXT, false);
|
||||
END;
|
||||
$get_user_settings_from_vesselid$ LANGUAGE plpgsql;
|
||||
|
||||
-- Create Windy PWS integration
|
||||
CREATE OR REPLACE FUNCTION public.windy_pws_py_fn(IN metric JSONB,
|
||||
IN _user JSONB, IN app JSONB) RETURNS JSONB
|
||||
AS $windy_pws_py$
|
||||
"""
|
||||
Send environment data from boat instruments to Windy as a Personal Weather Station (PWS)
|
||||
https://community.windy.com/topic/8168/report-your-weather-station-data-to-windy
|
||||
"""
|
||||
import requests
|
||||
import json
|
||||
import decimal
|
||||
|
||||
if not 'app.windy_apikey' in app and not app['app.windy_apikey']:
|
||||
plpy.error('Error no windy_apikey defined, check app settings')
|
||||
return none
|
||||
if not 'station' in metric and not metric['station']:
|
||||
plpy.error('Error no metrics defined')
|
||||
return none
|
||||
if not 'temp' in metric and not metric['temp']:
|
||||
plpy.error('Error no metrics defined')
|
||||
return none
|
||||
if not _user:
|
||||
plpy.error('Error no user defined, check user settings')
|
||||
return none
|
||||
|
||||
_headers = {'User-Agent': 'PostgSail', 'From': 'xbgmsharp@gmail.com', 'Content-Type': 'application/json'}
|
||||
_payload = {
|
||||
'stations': [
|
||||
{ 'station': int(decimal.Decimal(metric['station'])),
|
||||
'name': metric['name'],
|
||||
'shareOption': 'Open',
|
||||
'type': 'SignalK PostgSail Plugin',
|
||||
'provider': 'PostgSail',
|
||||
'url': 'https://iot.openplotter.cloud/{name}/monitoring'.format(name=metric['name']),
|
||||
'lat': float(decimal.Decimal(metric['lat'])),
|
||||
'lon': float(decimal.Decimal(metric['lon'])),
|
||||
'elevation': 1 }
|
||||
],
|
||||
'observations': [
|
||||
{ 'station': int(decimal.Decimal(metric['station'])),
|
||||
'temp': float(decimal.Decimal(metric['temp'])),
|
||||
'wind': round(float(decimal.Decimal(metric['wind']))),
|
||||
'gust': round(float(decimal.Decimal(metric['gust']))),
|
||||
'winddir': int(decimal.Decimal(metric['winddir'])),
|
||||
'pressure': int(decimal.Decimal(metric['pressure'])),
|
||||
'rh': float(decimal.Decimal(metric['rh'])) }
|
||||
]}
|
||||
#print(_payload)
|
||||
#plpy.notice(_payload)
|
||||
data = json.dumps(_payload)
|
||||
api_url = 'https://stations.windy.com/pws/update/{api_key}'.format(api_key=app['app.windy_apikey'])
|
||||
r = requests.post(api_url, data=data, headers=_headers, timeout=(5, 60))
|
||||
#print(r.text)
|
||||
#plpy.notice(api_url)
|
||||
if r.status_code == 200:
|
||||
#print('Data sent successfully!')
|
||||
plpy.notice('Data sent successfully to Windy!')
|
||||
#plpy.notice(api_url)
|
||||
if not 'windy' in _user['settings']:
|
||||
api_url = 'https://stations.windy.com/pws/station/{api_key}/{station}'.format(api_key=app['app.windy_apikey'], station=metric['station'])
|
||||
#print(r.text)
|
||||
#plpy.notice(api_url)
|
||||
r = requests.get(api_url, timeout=(5, 60))
|
||||
if r.status_code == 200:
|
||||
#print('Windy Personal Weather Station created successfully in Windy Stations!')
|
||||
plpy.notice('Windy Personal Weather Station created successfully in Windy Stations!')
|
||||
return r.json()
|
||||
else:
|
||||
plpy.error(f'Failed to gather PWS details. Status code: {r.status_code}')
|
||||
else:
|
||||
plpy.error(f'Failed to send data. Status code: {r.status_code}')
|
||||
#print(f'Failed to send data. Status code: {r.status_code}')
|
||||
#print(r.text)
|
||||
return {}
|
||||
$windy_pws_py$ strict TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.windy_pws_py_fn
|
||||
IS 'Forward vessel data to Windy as a Personal Weather Station using plpython3u';
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.cron_windy_fn() RETURNS void AS $cron_windy$
|
||||
DECLARE
|
||||
windy_rec record;
|
||||
default_last_metric TIMESTAMPTZ := NOW() - interval '1 day';
|
||||
last_metric TIMESTAMPTZ;
|
||||
metric_rec record;
|
||||
windy_metric jsonb;
|
||||
app_settings jsonb;
|
||||
user_settings jsonb;
|
||||
windy_pws jsonb;
|
||||
BEGIN
|
||||
-- Check for new observations pending update
|
||||
RAISE NOTICE 'cron_windy_fn';
|
||||
-- Gather url from app settings
|
||||
app_settings := get_app_settings_fn();
|
||||
-- Find users with Windy active and with an active vessel
|
||||
-- Map account id to Windy Station ID
|
||||
FOR windy_rec in
|
||||
SELECT
|
||||
a.id,a.email,v.vessel_id,v.name,
|
||||
COALESCE((a.preferences->'windy_last_metric')::TEXT, default_last_metric::TEXT) as last_metric
|
||||
FROM auth.accounts a
|
||||
LEFT JOIN auth.vessels AS v ON v.owner_email = a.email
|
||||
LEFT JOIN api.metadata AS m ON m.vessel_id = v.vessel_id
|
||||
WHERE (a.preferences->'public_windy')::boolean = True
|
||||
AND m.active = True
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_windy_fn for [%]', windy_rec;
|
||||
PERFORM set_config('vessel.id', windy_rec.vessel_id, false);
|
||||
--RAISE WARNING 'public.cron_process_windy_rec_fn() scheduler vessel.id %, user.id', current_setting('vessel.id', false), current_setting('user.id', false);
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(windy_rec.vessel_id::TEXT);
|
||||
RAISE NOTICE '-> cron_windy_fn checking user_settings [%]', user_settings;
|
||||
-- Get all metrics from the last windy_last_metric avg by 5 minutes
|
||||
-- TODO json_agg to send all data in once, but issue with py jsonb transformation decimal.
|
||||
FOR metric_rec in
|
||||
SELECT time_bucket('5 minutes', m.time) AS time_bucket,
|
||||
avg((m.metrics->'environment.outside.temperature')::numeric) AS temperature,
|
||||
avg((m.metrics->'environment.outside.pressure')::numeric) AS pressure,
|
||||
avg((m.metrics->'environment.outside.relativeHumidity')::numeric) AS rh,
|
||||
avg((m.metrics->'environment.wind.directionTrue')::numeric) AS winddir,
|
||||
avg((m.metrics->'environment.wind.speedTrue')::numeric) AS wind,
|
||||
max((m.metrics->'environment.wind.speedTrue')::numeric) AS gust,
|
||||
last(latitude, time) AS lat,
|
||||
last(longitude, time) AS lng
|
||||
FROM api.metrics m
|
||||
WHERE vessel_id = windy_rec.vessel_id
|
||||
AND m.time >= windy_rec.last_metric::TIMESTAMPTZ
|
||||
GROUP BY time_bucket
|
||||
ORDER BY time_bucket ASC LIMIT 100
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_windy_fn checking metrics [%]', metric_rec;
|
||||
IF metric_rec.wind IS NULL OR metric_rec.temperature IS NULL THEN
|
||||
-- Ignore when there is no metrics
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('windy_error'::TEXT, user_settings::JSONB);
|
||||
-- Disable windy
|
||||
PERFORM api.update_user_preferences_fn('{public_windy}'::TEXT, 'false'::TEXT);
|
||||
RETURN;
|
||||
END IF;
|
||||
-- https://community.windy.com/topic/8168/report-your-weather-station-data-to-windy
|
||||
-- temp from Kelvin to Celsius
|
||||
-- winddir from radiant to Degrees
|
||||
-- rh from ratio to percentage
|
||||
SELECT jsonb_build_object(
|
||||
'dateutc', metric_rec.time_bucket,
|
||||
'station', windy_rec.id,
|
||||
'name', windy_rec.name,
|
||||
'lat', metric_rec.lat,
|
||||
'lon', metric_rec.lng,
|
||||
'wind', metric_rec.wind,
|
||||
'gust', metric_rec.gust,
|
||||
'pressure', metric_rec.pressure,
|
||||
'winddir', radiantToDegrees(metric_rec.winddir::numeric),
|
||||
'temp', kelvinToCel(metric_rec.temperature::numeric),
|
||||
'rh', valToPercent(metric_rec.rh::numeric)
|
||||
) INTO windy_metric;
|
||||
RAISE NOTICE '-> cron_windy_fn checking windy_metrics [%]', windy_metric;
|
||||
SELECT windy_pws_py_fn(windy_metric, user_settings, app_settings) into windy_pws;
|
||||
RAISE NOTICE '-> cron_windy_fn Windy PWS [%]', ((windy_pws->'header')::JSONB ? 'id');
|
||||
IF NOT((user_settings->'settings')::JSONB ? 'windy') and ((windy_pws->'header')::JSONB ? 'id') then
|
||||
RAISE NOTICE '-> cron_windy_fn new Windy PWS [%]', (windy_pws->'header')::JSONB->>'id';
|
||||
-- Send metrics to Windy
|
||||
PERFORM api.update_user_preferences_fn('{windy}'::TEXT, ((windy_pws->'header')::JSONB->>'id')::TEXT);
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('windy'::TEXT, user_settings::JSONB);
|
||||
END IF;
|
||||
-- Record last metrics time
|
||||
SELECT metric_rec.time_bucket INTO last_metric;
|
||||
END LOOP;
|
||||
PERFORM api.update_user_preferences_fn('{windy_last_metric}'::TEXT, last_metric::TEXT);
|
||||
END LOOP;
|
||||
END;
|
||||
$cron_windy$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_windy_fn
|
||||
IS 'init by pg_cron to create (or update) station and uploading observations to Windy Personal Weather Station observations';
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.cron_alerts_fn() RETURNS void AS $$
|
||||
DECLARE
|
||||
alert_rec record;
|
||||
default_last_metric TIMESTAMPTZ := NOW() - interval '1 day';
|
||||
last_metric TIMESTAMPTZ;
|
||||
metric_rec record;
|
||||
app_settings JSONB;
|
||||
user_settings JSONB;
|
||||
alerting JSONB;
|
||||
_alarms JSONB;
|
||||
alarms TEXT;
|
||||
alert_default JSONB := '{
|
||||
"low_pressure_threshold": 990,
|
||||
"high_wind_speed_threshold": 30,
|
||||
"low_water_depth_threshold": 1,
|
||||
"min_notification_interval": 6,
|
||||
"high_pressure_drop_threshold": 12,
|
||||
"low_battery_charge_threshold": 90,
|
||||
"low_battery_voltage_threshold": 12.5,
|
||||
"low_water_temperature_threshold": 10,
|
||||
"low_indoor_temperature_threshold": 7,
|
||||
"low_outdoor_temperature_threshold": 3
|
||||
}';
|
||||
BEGIN
|
||||
-- Check for new event notification pending update
|
||||
RAISE NOTICE 'cron_alerts_fn';
|
||||
FOR alert_rec in
|
||||
SELECT
|
||||
a.user_id,a.email,v.vessel_id,
|
||||
COALESCE((a.preferences->'alert_last_metric')::TEXT, default_last_metric::TEXT) as last_metric,
|
||||
(alert_default || (a.preferences->'alerting')::JSONB) as alerting,
|
||||
(a.preferences->'alarms')::JSONB as alarms
|
||||
FROM auth.accounts a
|
||||
LEFT JOIN auth.vessels AS v ON v.owner_email = a.email
|
||||
LEFT JOIN api.metadata AS m ON m.vessel_id = v.vessel_id
|
||||
WHERE (a.preferences->'alerting'->'enabled')::boolean = True
|
||||
AND m.active = True
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_alerts_fn for [%]', alert_rec;
|
||||
PERFORM set_config('vessel.id', alert_rec.vessel_id, false);
|
||||
PERFORM set_config('user.email', alert_rec.email, false);
|
||||
--RAISE WARNING 'public.cron_process_alert_rec_fn() scheduler vessel.id %, user.id', current_setting('vessel.id', false), current_setting('user.id', false);
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(alert_rec.vessel_id::TEXT);
|
||||
RAISE NOTICE '-> cron_alerts_fn checking user_settings [%]', user_settings;
|
||||
-- Get all metrics from the last last_metric avg by 5 minutes
|
||||
FOR metric_rec in
|
||||
SELECT time_bucket('5 minutes', m.time) AS time_bucket,
|
||||
avg((m.metrics->'environment.inside.temperature')::numeric) AS intemp,
|
||||
avg((m.metrics->'environment.outside.temperature')::numeric) AS outtemp,
|
||||
avg((m.metrics->'environment.water.temperature')::numeric) AS wattemp,
|
||||
avg((m.metrics->'environment.depth.belowTransducer')::numeric) AS watdepth,
|
||||
avg((m.metrics->'environment.outside.pressure')::numeric) AS pressure,
|
||||
avg((m.metrics->'environment.wind.speedTrue')::numeric) AS wind,
|
||||
avg((m.metrics->'electrical.batteries.House.voltage')::numeric) AS voltage,
|
||||
avg((m.metrics->'electrical.batteries.House.capacity.stateOfCharge')::numeric) AS charge
|
||||
FROM api.metrics m
|
||||
WHERE vessel_id = alert_rec.vessel_id
|
||||
AND m.time >= alert_rec.last_metric::TIMESTAMPTZ
|
||||
GROUP BY time_bucket
|
||||
ORDER BY time_bucket ASC LIMIT 100
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_alerts_fn checking metrics [%]', metric_rec;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking alerting [%]', alert_rec.alerting;
|
||||
--RAISE NOTICE '-> cron_alerts_fn checking debug [%] [%]', kelvinToCel(metric_rec.intemp), (alert_rec.alerting->'low_indoor_temperature_threshold');
|
||||
IF kelvinToCel(metric_rec.intemp) < (alert_rec.alerting->'low_indoor_temperature_threshold')::numeric then
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_indoor_temperature_threshold'->>'date')::TIMESTAMPTZ;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', metric_rec.time_bucket::TIMESTAMPTZ;
|
||||
-- Get latest alarms
|
||||
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
|
||||
-- Is alarm in the min_notification_interval time frame
|
||||
IF (
|
||||
((_alarms->'low_indoor_temperature_threshold'->>'date') IS NULL) OR
|
||||
(((_alarms->'low_indoor_temperature_threshold'->>'date')::TIMESTAMPTZ
|
||||
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
|
||||
< metric_rec.time_bucket::TIMESTAMPTZ)
|
||||
) THEN
|
||||
-- Add alarm
|
||||
alarms := '{"low_indoor_temperature_threshold": {"value": '|| kelvinToCel(metric_rec.intemp) ||', "date":"' || metric_rec.time_bucket || '"}}';
|
||||
-- Merge alarms
|
||||
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
|
||||
-- Update alarms for user
|
||||
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
|
||||
SELECT user_settings::JSONB || ('{"alert": "low_outdoor_temperature_threshold value:'|| kelvinToCel(metric_rec.intemp) ||'"}'::text)::JSONB into user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
|
||||
-- DEBUG
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_indoor_temperature_threshold +interval';
|
||||
END IF;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_indoor_temperature_threshold';
|
||||
END IF;
|
||||
IF kelvinToCel(metric_rec.outtemp) < (alert_rec.alerting->'low_outdoor_temperature_threshold')::numeric then
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_outdoor_temperature_threshold'->>'date')::TIMESTAMPTZ;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', metric_rec.time_bucket::TIMESTAMPTZ;
|
||||
-- Get latest alarms
|
||||
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
|
||||
-- Is alarm in the min_notification_interval time frame
|
||||
IF (
|
||||
((_alarms->'low_outdoor_temperature_threshold'->>'date') IS NULL) OR
|
||||
(((_alarms->'low_outdoor_temperature_threshold'->>'date')::TIMESTAMPTZ
|
||||
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
|
||||
< metric_rec.time_bucket::TIMESTAMPTZ)
|
||||
) THEN
|
||||
-- Add alarm
|
||||
alarms := '{"low_outdoor_temperature_threshold": {"value": '|| kelvinToCel(metric_rec.outtemp) ||', "date":"' || metric_rec.time_bucket || '"}}';
|
||||
-- Merge alarms
|
||||
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
|
||||
-- Update alarms for user
|
||||
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
|
||||
SELECT user_settings::JSONB || ('{"alert": "low_outdoor_temperature_threshold value:'|| kelvinToCel(metric_rec.outtemp) ||'"}'::text)::JSONB into user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
|
||||
-- DEBUG
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_outdoor_temperature_threshold +interval';
|
||||
END IF;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_outdoor_temperature_threshold';
|
||||
END IF;
|
||||
IF kelvinToCel(metric_rec.wattemp) < (alert_rec.alerting->'low_water_temperature_threshold')::numeric then
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_water_temperature_threshold'->>'date')::TIMESTAMPTZ;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', metric_rec.time_bucket::TIMESTAMPTZ;
|
||||
-- Get latest alarms
|
||||
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
|
||||
-- Is alarm in the min_notification_interval time frame
|
||||
IF (
|
||||
((_alarms->'low_water_temperature_threshold'->>'date') IS NULL) OR
|
||||
(((_alarms->'low_water_temperature_threshold'->>'date')::TIMESTAMPTZ
|
||||
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
|
||||
< metric_rec.time_bucket::TIMESTAMPTZ)
|
||||
) THEN
|
||||
-- Add alarm
|
||||
alarms := '{"low_water_temperature_threshold": {"value": '|| kelvinToCel(metric_rec.wattemp) ||', "date":"' || metric_rec.time_bucket || '"}}';
|
||||
-- Merge alarms
|
||||
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
|
||||
-- Update alarms for user
|
||||
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
|
||||
SELECT user_settings::JSONB || ('{"alert": "low_water_temperature_threshold value:'|| kelvinToCel(metric_rec.wattemp) ||'"}'::text)::JSONB into user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
|
||||
-- DEBUG
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_water_temperature_threshold +interval';
|
||||
END IF;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_water_temperature_threshold';
|
||||
END IF;
|
||||
IF metric_rec.watdepth < (alert_rec.alerting->'low_water_depth_threshold')::numeric then
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_water_depth_threshold'->>'date')::TIMESTAMPTZ;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', metric_rec.time_bucket::TIMESTAMPTZ;
|
||||
-- Get latest alarms
|
||||
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
|
||||
-- Is alarm in the min_notification_interval time frame
|
||||
IF (
|
||||
((_alarms->'low_water_depth_threshold'->>'date') IS NULL) OR
|
||||
(((_alarms->'low_water_depth_threshold'->>'date')::TIMESTAMPTZ
|
||||
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
|
||||
< metric_rec.time_bucket::TIMESTAMPTZ)
|
||||
) THEN
|
||||
-- Add alarm
|
||||
alarms := '{"low_water_depth_threshold": {"value": '|| metric_rec.watdepth ||', "date":"' || metric_rec.time_bucket || '"}}';
|
||||
-- Merge alarms
|
||||
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
|
||||
-- Update alarms for user
|
||||
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
|
||||
SELECT user_settings::JSONB || ('{"alert": "low_water_depth_threshold value:'|| metric_rec.watdepth ||'"}'::text)::JSONB into user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
|
||||
-- DEBUG
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_water_depth_threshold +interval';
|
||||
END IF;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_water_depth_threshold';
|
||||
END IF;
|
||||
if metric_rec.pressure < (alert_rec.alerting->'high_pressure_drop_threshold')::numeric then
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'high_pressure_drop_threshold'->>'date')::TIMESTAMPTZ;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', metric_rec.time_bucket::TIMESTAMPTZ;
|
||||
-- Get latest alarms
|
||||
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
|
||||
-- Is alarm in the min_notification_interval time frame
|
||||
IF (
|
||||
((_alarms->'high_pressure_drop_threshold'->>'date') IS NULL) OR
|
||||
(((_alarms->'high_pressure_drop_threshold'->>'date')::TIMESTAMPTZ
|
||||
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
|
||||
< metric_rec.time_bucket::TIMESTAMPTZ)
|
||||
) THEN
|
||||
-- Add alarm
|
||||
alarms := '{"high_pressure_drop_threshold": {"value": '|| metric_rec.pressure ||', "date":"' || metric_rec.time_bucket || '"}}';
|
||||
-- Merge alarms
|
||||
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
|
||||
-- Update alarms for user
|
||||
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
|
||||
SELECT user_settings::JSONB || ('{"alert": "high_pressure_drop_threshold value:'|| metric_rec.pressure ||'"}'::text)::JSONB into user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
|
||||
-- DEBUG
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug high_pressure_drop_threshold +interval';
|
||||
END IF;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug high_pressure_drop_threshold';
|
||||
END IF;
|
||||
IF metric_rec.wind > (alert_rec.alerting->'high_wind_speed_threshold')::numeric then
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'high_wind_speed_threshold'->>'date')::TIMESTAMPTZ;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', metric_rec.time_bucket::TIMESTAMPTZ;
|
||||
-- Get latest alarms
|
||||
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
|
||||
-- Is alarm in the min_notification_interval time frame
|
||||
IF (
|
||||
((_alarms->'high_wind_speed_threshold'->>'date') IS NULL) OR
|
||||
(((_alarms->'high_wind_speed_threshold'->>'date')::TIMESTAMPTZ
|
||||
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
|
||||
< metric_rec.time_bucket::TIMESTAMPTZ)
|
||||
) THEN
|
||||
-- Add alarm
|
||||
alarms := '{"high_wind_speed_threshold": {"value": '|| metric_rec.wind ||', "date":"' || metric_rec.time_bucket || '"}}';
|
||||
-- Merge alarms
|
||||
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
|
||||
-- Update alarms for user
|
||||
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
|
||||
SELECT user_settings::JSONB || ('{"alert": "high_wind_speed_threshold value:'|| metric_rec.wind ||'"}'::text)::JSONB into user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
|
||||
-- DEBUG
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug high_wind_speed_threshold +interval';
|
||||
END IF;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug high_wind_speed_threshold';
|
||||
END IF;
|
||||
if metric_rec.voltage < (alert_rec.alerting->'low_battery_voltage_threshold')::numeric then
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_battery_voltage_threshold'->>'date')::TIMESTAMPTZ;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', metric_rec.time_bucket::TIMESTAMPTZ;
|
||||
-- Get latest alarms
|
||||
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = 'lacroix.francois@gmail.com';
|
||||
-- Is alarm in the min_notification_interval time frame
|
||||
IF (
|
||||
((_alarms->'low_battery_voltage_threshold'->>'date') IS NULL) OR
|
||||
(((_alarms->'low_battery_voltage_threshold'->>'date')::TIMESTAMPTZ
|
||||
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
|
||||
< metric_rec.time_bucket::TIMESTAMPTZ)
|
||||
) THEN
|
||||
-- Add alarm
|
||||
alarms := '{"low_battery_voltage_threshold": {"value": '|| metric_rec.voltage ||', "date":"' || metric_rec.time_bucket || '"}}';
|
||||
-- Merge alarms
|
||||
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
|
||||
-- Update alarms for user
|
||||
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
|
||||
SELECT user_settings::JSONB || ('{"alert": "low_battery_voltage_threshold value:'|| metric_rec.voltage ||'"}'::text)::JSONB into user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
|
||||
-- DEBUG
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_battery_voltage_threshold +interval';
|
||||
END IF;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_battery_voltage_threshold';
|
||||
END IF;
|
||||
if (metric_rec.charge*100) < (alert_rec.alerting->'low_battery_charge_threshold')::numeric then
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', (alert_rec.alarms->'low_battery_charge_threshold'->>'date')::TIMESTAMPTZ;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug [%]', metric_rec.time_bucket::TIMESTAMPTZ;
|
||||
-- Get latest alarms
|
||||
SELECT preferences->'alarms' INTO _alarms FROM auth.accounts a WHERE a.email = current_setting('user.email', false);
|
||||
-- Is alarm in the min_notification_interval time frame
|
||||
IF (
|
||||
((_alarms->'low_battery_charge_threshold'->>'date') IS NULL) OR
|
||||
(((_alarms->'low_battery_charge_threshold'->>'date')::TIMESTAMPTZ
|
||||
+ ((interval '1 hour') * (alert_rec.alerting->>'min_notification_interval')::NUMERIC))
|
||||
< metric_rec.time_bucket::TIMESTAMPTZ)
|
||||
) THEN
|
||||
-- Add alarm
|
||||
alarms := '{"low_battery_charge_threshold": {"value": '|| (metric_rec.charge*100) ||', "date":"' || metric_rec.time_bucket || '"}}';
|
||||
-- Merge alarms
|
||||
SELECT public.jsonb_recursive_merge(_alarms::jsonb, alarms::jsonb) into _alarms;
|
||||
-- Update alarms for user
|
||||
PERFORM api.update_user_preferences_fn('{alarms}'::TEXT, _alarms::TEXT);
|
||||
-- Gather user settings
|
||||
user_settings := get_user_settings_from_vesselid_fn(current_setting('vessel.id', false));
|
||||
SELECT user_settings::JSONB || ('{"alert": "low_battery_charge_threshold value:'|| (metric_rec.charge*100) ||'"}'::text)::JSONB into user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('alert'::TEXT, user_settings::JSONB);
|
||||
-- DEBUG
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_battery_charge_threshold +interval';
|
||||
END IF;
|
||||
RAISE NOTICE '-> cron_alerts_fn checking debug low_battery_charge_threshold';
|
||||
END IF;
|
||||
-- Record last metrics time
|
||||
SELECT metric_rec.time_bucket INTO last_metric;
|
||||
END LOOP;
|
||||
PERFORM api.update_user_preferences_fn('{alert_last_metric}'::TEXT, last_metric::TEXT);
|
||||
END LOOP;
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_alerts_fn
|
||||
IS 'init by pg_cron to check for alerts';
|
||||
|
||||
-- CRON for no vessel notification
|
||||
CREATE FUNCTION public.cron_no_vessel_fn() RETURNS void AS $no_vessel$
|
||||
DECLARE
|
||||
no_vessel record;
|
||||
user_settings jsonb;
|
||||
BEGIN
|
||||
-- Check for user with no vessel register
|
||||
RAISE NOTICE 'cron_no_vessel_fn';
|
||||
FOR no_vessel in
|
||||
SELECT a.user_id,a.email,a.first
|
||||
FROM auth.accounts a
|
||||
WHERE NOT EXISTS (
|
||||
SELECT *
|
||||
FROM auth.vessels v
|
||||
WHERE v.owner_email = a.email)
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_no_vessel_rec_fn for [%]', no_vessel;
|
||||
SELECT json_build_object('email', no_vessel.email, 'recipient', no_vessel.first) into user_settings;
|
||||
RAISE NOTICE '-> debug cron_no_vessel_rec_fn [%]', user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('no_vessel'::TEXT, user_settings::JSONB);
|
||||
END LOOP;
|
||||
END;
|
||||
$no_vessel$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_no_vessel_fn
|
||||
IS 'init by pg_cron, check for user with no vessel register then send notification';
|
||||
|
||||
CREATE FUNCTION public.cron_no_metadata_fn() RETURNS void AS $no_metadata$
|
||||
DECLARE
|
||||
no_metadata_rec record;
|
||||
user_settings jsonb;
|
||||
BEGIN
|
||||
-- Check for vessel register but with no metadata
|
||||
RAISE NOTICE 'cron_no_metadata_fn';
|
||||
FOR no_metadata_rec in
|
||||
SELECT
|
||||
a.user_id,a.email,a.first
|
||||
FROM auth.accounts a, auth.vessels v
|
||||
WHERE NOT EXISTS (
|
||||
SELECT *
|
||||
FROM api.metadata m
|
||||
WHERE v.vessel_id = m.vessel_id) AND v.owner_email = a.email
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_process_no_metadata_rec_fn for [%]', no_metadata_rec;
|
||||
SELECT json_build_object('email', no_metadata_rec.email, 'recipient', no_metadata_rec.first) into user_settings;
|
||||
RAISE NOTICE '-> debug cron_process_no_metadata_rec_fn [%]', user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('no_metadata'::TEXT, user_settings::JSONB);
|
||||
END LOOP;
|
||||
END;
|
||||
$no_metadata$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_no_metadata_fn
|
||||
IS 'init by pg_cron, check for vessel with no metadata then send notification';
|
||||
|
||||
CREATE FUNCTION public.cron_no_activity_fn() RETURNS void AS $no_activity$
|
||||
DECLARE
|
||||
no_activity_rec record;
|
||||
user_settings jsonb;
|
||||
BEGIN
|
||||
-- Check for vessel with no activity for more than 230 days
|
||||
RAISE NOTICE 'cron_no_activity_fn';
|
||||
FOR no_activity_rec in
|
||||
SELECT
|
||||
v.owner_email,m.name,m.vessel_id,m.time,a.first
|
||||
FROM auth.accounts a
|
||||
LEFT JOIN auth.vessels v ON v.owner_email = a.email
|
||||
LEFT JOIN api.metadata m ON v.vessel_id = m.vessel_id
|
||||
WHERE m.time < NOW() AT TIME ZONE 'UTC' - INTERVAL '230 DAYS'
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_process_no_activity_rec_fn for [%]', no_activity_rec;
|
||||
SELECT json_build_object('email', no_activity_rec.owner_email, 'recipient', no_activity_rec.first) into user_settings;
|
||||
RAISE NOTICE '-> debug cron_process_no_activity_rec_fn [%]', user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('no_activity'::TEXT, user_settings::JSONB);
|
||||
END LOOP;
|
||||
END;
|
||||
$no_activity$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_no_activity_fn
|
||||
IS 'init by pg_cron, check for vessel with no activity for more than 230 days then send notification';
|
||||
|
||||
CREATE FUNCTION public.cron_deactivated_fn() RETURNS void AS $deactivated$
|
||||
DECLARE
|
||||
no_activity_rec record;
|
||||
user_settings jsonb;
|
||||
BEGIN
|
||||
RAISE NOTICE 'cron_deactivated_fn';
|
||||
|
||||
-- List accounts with vessel inactivity for more than 1 YEAR
|
||||
FOR no_activity_rec in
|
||||
SELECT
|
||||
v.owner_email,m.name,m.vessel_id,m.time,a.first
|
||||
FROM auth.accounts a
|
||||
LEFT JOIN auth.vessels v ON v.owner_email = a.email
|
||||
LEFT JOIN api.metadata m ON v.vessel_id = m.vessel_id
|
||||
WHERE m.time < NOW() AT TIME ZONE 'UTC' - INTERVAL '1 YEAR'
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_process_deactivated_rec_fn for inactivity [%]', no_activity_rec;
|
||||
SELECT json_build_object('email', no_activity_rec.owner_email, 'recipient', no_activity_rec.first) into user_settings;
|
||||
RAISE NOTICE '-> debug cron_process_deactivated_rec_fn inactivity [%]', user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('deactivated'::TEXT, user_settings::JSONB);
|
||||
--PERFORM public.delete_account_fn(no_activity_rec.owner_email::TEXT, no_activity_rec.vessel_id::TEXT);
|
||||
END LOOP;
|
||||
|
||||
-- List accounts with no vessel metadata for more than 1 YEAR
|
||||
FOR no_activity_rec in
|
||||
SELECT
|
||||
a.user_id,a.email,a.first,a.created_at
|
||||
FROM auth.accounts a, auth.vessels v
|
||||
WHERE NOT EXISTS (
|
||||
SELECT *
|
||||
FROM api.metadata m
|
||||
WHERE v.vessel_id = m.vessel_id) AND v.owner_email = a.email
|
||||
AND v.created_at < NOW() AT TIME ZONE 'UTC' - INTERVAL '1 YEAR'
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_process_deactivated_rec_fn for no metadata [%]', no_activity_rec;
|
||||
SELECT json_build_object('email', no_activity_rec.owner_email, 'recipient', no_activity_rec.first) into user_settings;
|
||||
RAISE NOTICE '-> debug cron_process_deactivated_rec_fn no metadata [%]', user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('deactivated'::TEXT, user_settings::JSONB);
|
||||
--PERFORM public.delete_account_fn(no_activity_rec.owner_email::TEXT, no_activity_rec.vessel_id::TEXT);
|
||||
END LOOP;
|
||||
|
||||
-- List accounts with no vessel created for more than 1 YEAR
|
||||
FOR no_activity_rec in
|
||||
SELECT a.user_id,a.email,a.first,a.created_at
|
||||
FROM auth.accounts a
|
||||
WHERE NOT EXISTS (
|
||||
SELECT *
|
||||
FROM auth.vessels v
|
||||
WHERE v.owner_email = a.email)
|
||||
AND a.created_at < NOW() AT TIME ZONE 'UTC' - INTERVAL '1 YEAR'
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_process_deactivated_rec_fn for no vessel [%]', no_activity_rec;
|
||||
SELECT json_build_object('email', no_activity_rec.owner_email, 'recipient', no_activity_rec.first) into user_settings;
|
||||
RAISE NOTICE '-> debug cron_process_deactivated_rec_fn no vessel [%]', user_settings;
|
||||
-- Send notification
|
||||
PERFORM send_notification_fn('deactivated'::TEXT, user_settings::JSONB);
|
||||
--PERFORM public.delete_account_fn(no_activity_rec.owner_email::TEXT, no_activity_rec.vessel_id::TEXT);
|
||||
END LOOP;
|
||||
END;
|
||||
$deactivated$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_deactivated_fn
|
||||
IS 'init by pg_cron, check for vessel with no activity for more than 1 year then send notification and delete data';
|
||||
|
||||
DROP FUNCTION IF EXISTS public.cron_prune_otp_fn;
|
||||
CREATE OR REPLACE FUNCTION public.cron_prune_otp_fn() RETURNS void
|
||||
AS $$
|
||||
DECLARE
|
||||
otp_rec record;
|
||||
BEGIN
|
||||
-- Purge OTP older than 15 minutes
|
||||
RAISE NOTICE 'cron_prune_otp_fn';
|
||||
FOR otp_rec in
|
||||
SELECT *
|
||||
FROM auth.otp
|
||||
WHERE otp_timestamp < NOW() AT TIME ZONE 'UTC' - INTERVAL '15 MINUTES'
|
||||
ORDER BY otp_timestamp desc
|
||||
LOOP
|
||||
RAISE NOTICE '-> cron_prune_otp_fn deleting expired otp for user [%]', otp_rec.user_email;
|
||||
-- remove entry
|
||||
DELETE FROM auth.otp
|
||||
WHERE user_email = otp_rec.user_email;
|
||||
RAISE NOTICE '-> cron_prune_otp_fn deleted expire otp for user [%]', otp_rec.user_email;
|
||||
END LOOP;
|
||||
END;
|
||||
$$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.cron_prune_otp_fn
|
||||
IS 'init by pg_cron to purge older than 15 minutes OTP token';
|
||||
|
||||
DROP FUNCTION IF EXISTS public.cron_process_prune_otp_fn();
|
||||
DROP FUNCTION IF EXISTS public.cron_process_no_vessel_fn();
|
||||
DROP FUNCTION IF EXISTS public.cron_process_no_metadata_fn();
|
||||
DROP FUNCTION IF EXISTS public.cron_process_no_activity_fn();
|
||||
DROP FUNCTION IF EXISTS public.cron_process_deactivated_fn();
|
||||
DROP FUNCTION IF EXISTS public.cron_process_windy_fn();
|
||||
DROP FUNCTION IF EXISTS public.cron_process_alerts_fn();
|
||||
|
||||
-- Remove deprecated fn
|
||||
DROP FUNCTION IF EXISTS public.cron_process_new_account_fn();
|
||||
DROP FUNCTION IF EXISTS public.cron_process_new_account_otp_validation_fn();
|
||||
DROP FUNCTION IF EXISTS public.cron_process_new_moorage_fn();
|
||||
DROP FUNCTION IF EXISTS public.cron_process_new_vessel_fn();
|
||||
|
||||
CREATE OR REPLACE FUNCTION send_notification_fn(
|
||||
IN email_type TEXT,
|
||||
IN user_settings JSONB) RETURNS VOID
|
||||
AS $send_notification$
|
||||
DECLARE
|
||||
app_settings JSONB;
|
||||
_email_notifications BOOLEAN := False;
|
||||
_phone_notifications BOOLEAN := False;
|
||||
_pushover_user_key TEXT := NULL;
|
||||
pushover_settings JSONB := NULL;
|
||||
_telegram_notifications BOOLEAN := False;
|
||||
_telegram_chat_id TEXT := NULL;
|
||||
telegram_settings JSONB := NULL;
|
||||
_email TEXT := NULL;
|
||||
BEGIN
|
||||
-- TODO input check
|
||||
--RAISE NOTICE '--> send_notification_fn type [%]', email_type;
|
||||
-- Gather notification app settings, eg: email, pushover, telegram
|
||||
app_settings := get_app_settings_fn();
|
||||
--RAISE NOTICE '--> send_notification_fn app_settings [%]', app_settings;
|
||||
--RAISE NOTICE '--> user_settings [%]', user_settings->>'email'::TEXT;
|
||||
|
||||
-- Gather notifications settings and merge with user settings
|
||||
-- Send notification email
|
||||
SELECT preferences['email_notifications'] INTO _email_notifications
|
||||
FROM auth.accounts a
|
||||
WHERE a.email = user_settings->>'email'::TEXT;
|
||||
RAISE NOTICE '--> send_notification_fn email_notifications [%]', _email_notifications;
|
||||
-- If email server app settings set and if email user settings set
|
||||
IF app_settings['app.email_server'] IS NOT NULL AND _email_notifications IS True THEN
|
||||
PERFORM send_email_py_fn(email_type::TEXT, user_settings::JSONB, app_settings::JSONB);
|
||||
END IF;
|
||||
|
||||
-- Send notification pushover
|
||||
SELECT preferences['phone_notifications'],preferences->>'pushover_user_key' INTO _phone_notifications,_pushover_user_key
|
||||
FROM auth.accounts a
|
||||
WHERE a.email = user_settings->>'email'::TEXT;
|
||||
RAISE NOTICE '--> send_notification_fn phone_notifications [%]', _phone_notifications;
|
||||
-- If pushover app settings set and if pushover user settings set
|
||||
IF app_settings['app.pushover_app_token'] IS NOT NULL AND _phone_notifications IS True AND _pushover_user_key IS NOT NULL THEN
|
||||
SELECT json_build_object('pushover_user_key', _pushover_user_key) into pushover_settings;
|
||||
SELECT user_settings::JSONB || pushover_settings::JSONB into user_settings;
|
||||
--RAISE NOTICE '--> send_notification_fn user_settings + pushover [%]', user_settings;
|
||||
PERFORM send_pushover_py_fn(email_type::TEXT, user_settings::JSONB, app_settings::JSONB);
|
||||
END IF;
|
||||
|
||||
-- Send notification telegram
|
||||
SELECT (preferences->'telegram'->'chat'->'id') IS NOT NULL,preferences['telegram']['chat']['id'] INTO _telegram_notifications,_telegram_chat_id
|
||||
FROM auth.accounts a
|
||||
WHERE a.email = user_settings->>'email'::TEXT;
|
||||
RAISE NOTICE '--> send_notification_fn telegram_notifications [%]', _telegram_notifications;
|
||||
-- If telegram app settings set and if telegram user settings set
|
||||
IF app_settings['app.telegram_bot_token'] IS NOT NULL AND _telegram_notifications IS True AND _phone_notifications IS True THEN
|
||||
SELECT json_build_object('telegram_chat_id', _telegram_chat_id) into telegram_settings;
|
||||
SELECT user_settings::JSONB || telegram_settings::JSONB into user_settings;
|
||||
--RAISE NOTICE '--> send_notification_fn user_settings + telegram [%]', user_settings;
|
||||
PERFORM send_telegram_py_fn(email_type::TEXT, user_settings::JSONB, app_settings::JSONB);
|
||||
END IF;
|
||||
END;
|
||||
$send_notification$ LANGUAGE plpgsql;
|
||||
|
||||
-- fn to trim new vessel name
|
||||
CREATE FUNCTION new_vessel_trim_fn() RETURNS trigger AS $new_vessel_trim_fn$
|
||||
BEGIN
|
||||
NEW.name := TRIM(NEW.name);
|
||||
RETURN NEW;
|
||||
END;
|
||||
$new_vessel_trim_fn$ language plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.new_vessel_trim_fn
|
||||
IS 'Trim space vessel name';
|
||||
-- Trigger trim new vessel name
|
||||
CREATE TRIGGER new_vessel_trim BEFORE INSERT ON auth.vessels
|
||||
FOR EACH ROW EXECUTE FUNCTION public.new_vessel_trim_fn();
|
||||
-- Description
|
||||
COMMENT ON TRIGGER new_vessel_trim
|
||||
ON auth.vessels
|
||||
IS 'Trim space vessel name';
|
||||
|
||||
-- Update version
|
||||
UPDATE public.app_settings
|
||||
SET value='0.7.0'
|
||||
WHERE "name"='app.version';
|
||||
|
||||
-- Create a cron job
|
||||
\c postgres
|
||||
|
||||
UPDATE cron.job
|
||||
SET command='select public.cron_prune_otp_fn()'
|
||||
WHERE jobname = 'cron_prune_otp';
|
||||
UPDATE cron.job
|
||||
SET command='select public.cron_no_vessel_fn()'
|
||||
WHERE jobname = 'cron_no_vessel';
|
||||
UPDATE cron.job
|
||||
SET command='select public.cron_no_metadata_fn()'
|
||||
WHERE jobname = 'cron_no_metadata';
|
||||
UPDATE cron.job
|
||||
SET command='select public.cron_no_activity_fn()'
|
||||
WHERE jobname = 'cron_no_activity';
|
||||
UPDATE cron.job
|
||||
SET command='select public.cron_windy_fn()'
|
||||
WHERE jobname = 'cron_windy';
|
||||
UPDATE cron.job
|
||||
SET command='select public.cron_alerts_fn()'
|
||||
WHERE jobname = 'cron_alerts';
|
||||
|
30
initdb/99env.sh
Executable file
30
initdb/99env.sh
Executable file
@@ -0,0 +1,30 @@
|
||||
|
||||
#------------------------------------------------------------------------------
|
||||
# ENV Settings
|
||||
#------------------------------------------------------------------------------
|
||||
echo "Set password and settings from environment variables"
|
||||
|
||||
PGSAIL_VERSION=`cat /docker-entrypoint-initdb.d/PGSAIL_VERSION`
|
||||
|
||||
psql -U ${POSTGRES_USER} signalk <<-END
|
||||
-- Application settings default
|
||||
INSERT INTO app_settings (name, value) VALUES
|
||||
('app.jwt_secret', '${PGRST_JWT_SECRET}'),
|
||||
('app.email_server', '${PGSAIL_EMAIL_SERVER}'),
|
||||
('app.email_user', '${PGSAIL_EMAIL_USER}'),
|
||||
('app.email_pass', '${PGSAIL_EMAIL_PASS}'),
|
||||
('app.email_from', '${PGSAIL_EMAIL_FROM}'),
|
||||
('app.pushover_app_token', '${PGSAIL_PUSHOVER_APP_TOKEN}'),
|
||||
('app.pushover_app_url', '${PGSAIL_PUSHOVER_APP_URL}'),
|
||||
('app.telegram_bot_token', '${PGSAIL_TELEGRAM_BOT_TOKEN}'),
|
||||
('app.grafana_admin_uri', '${PGSAIL_GRAFANA_ADMIN_URI}'),
|
||||
('app.keycloak_uri', '${PGSAIL_KEYCLOAK_URI}'),
|
||||
('app.url', '${PGSAIL_APP_URL}'),
|
||||
('app.version', '${PGSAIL_VERSION}');
|
||||
-- Update comment with version
|
||||
COMMENT ON DATABASE signalk IS 'PostgSail version ${PGSAIL_VERSION}';
|
||||
-- Update password from env
|
||||
ALTER ROLE authenticator WITH PASSWORD '${PGSAIL_AUTHENTICATOR_PASSWORD}';
|
||||
ALTER ROLE grafana WITH PASSWORD '${PGSAIL_GRAFANA_PASSWORD}';
|
||||
ALTER ROLE grafana_auth WITH PASSWORD '${PGSAIL_GRAFANA_AUTH_PASSWORD}';
|
||||
END
|
1
initdb/PGSAIL_VERSION
Normal file
1
initdb/PGSAIL_VERSION
Normal file
@@ -0,0 +1 @@
|
||||
0.7.0
|
310
initdb/ne_10m_geography_marine_polys.csv
Normal file
310
initdb/ne_10m_geography_marine_polys.csv
Normal file
File diff suppressed because one or more lines are too long
Reference in New Issue
Block a user