mirror of
https://github.com/xbgmsharp/postgsail.git
synced 2025-09-17 19:27:49 +00:00
Compare commits
22 Commits
Author | SHA1 | Date | |
---|---|---|---|
![]() |
852d2ff583 | ||
![]() |
7cf7905694 | ||
![]() |
0f8107a672 | ||
![]() |
77dec463d1 | ||
![]() |
8ff1d0a8ed | ||
![]() |
859788d98d | ||
![]() |
62642ffbd6 | ||
![]() |
c3760c8689 | ||
![]() |
763c9ae802 | ||
![]() |
37abb3ae1f | ||
![]() |
a6da3cab0a | ||
![]() |
22f756b3a9 | ||
![]() |
cb3e9d8e57 | ||
![]() |
1997fe5a81 | ||
![]() |
5a1451ff69 | ||
![]() |
a18abec1f1 | ||
![]() |
322c3ed4fb | ||
![]() |
d648d119cc | ||
![]() |
9109474e8a | ||
![]() |
ca92a15eba | ||
![]() |
d745048a9c | ||
![]() |
6a0c15d23c |
@@ -409,6 +409,11 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
|
|||||||
RAISE WARNING 'Metrics Ignoring metric, duplicate time [%] = [%]', previous_time, NEW.time;
|
RAISE WARNING 'Metrics Ignoring metric, duplicate time [%] = [%]', previous_time, NEW.time;
|
||||||
RETURN NULL;
|
RETURN NULL;
|
||||||
END IF;
|
END IF;
|
||||||
|
IF previous_time > NEW.time THEN
|
||||||
|
-- Ignore entry if new time is later than previous time
|
||||||
|
RAISE WARNING 'Metrics Ignoring metric, new time is older [%] > [%]', previous_time, NEW.time;
|
||||||
|
RETURN NULL;
|
||||||
|
END IF;
|
||||||
-- Check if latitude or longitude are null
|
-- Check if latitude or longitude are null
|
||||||
IF NEW.latitude IS NULL OR NEW.longitude IS NULL THEN
|
IF NEW.latitude IS NULL OR NEW.longitude IS NULL THEN
|
||||||
-- Ignore entry if null latitude,longitude
|
-- Ignore entry if null latitude,longitude
|
||||||
@@ -431,10 +436,11 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
|
|||||||
-- Add new stay as no previous entry exist
|
-- Add new stay as no previous entry exist
|
||||||
INSERT INTO api.stays
|
INSERT INTO api.stays
|
||||||
(client_id, active, arrived, latitude, longitude, stay_code)
|
(client_id, active, arrived, latitude, longitude, stay_code)
|
||||||
VALUES (NEW.client_id, true, NEW.time, NEW.latitude, NEW.longitude, stay_code)
|
VALUES (NEW.client_id, true, NEW.time, NEW.latitude, NEW.longitude, 1)
|
||||||
RETURNING id INTO stay_id;
|
RETURNING id INTO stay_id;
|
||||||
-- Add stay entry to process queue for further processing
|
-- Add stay entry to process queue for further processing
|
||||||
INSERT INTO process_queue (channel, payload, stored) values ('new_stay', stay_id, now());
|
INSERT INTO process_queue (channel, payload, stored)
|
||||||
|
VALUES ('new_stay', stay_id, now());
|
||||||
RAISE WARNING 'Metrics Insert first stay as no previous metrics exist, stay_id %', stay_id;
|
RAISE WARNING 'Metrics Insert first stay as no previous metrics exist, stay_id %', stay_id;
|
||||||
END IF;
|
END IF;
|
||||||
-- Check if status is valid enum
|
-- Check if status is valid enum
|
||||||
@@ -480,7 +486,8 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
|
|||||||
WHERE id = stay_id;
|
WHERE id = stay_id;
|
||||||
RAISE WARNING 'Metrics Updating Stay end current stay_id [%] [%] [%]', stay_id, NEW.status, NEW.time;
|
RAISE WARNING 'Metrics Updating Stay end current stay_id [%] [%] [%]', stay_id, NEW.status, NEW.time;
|
||||||
-- Add moorage entry to process queue for further processing
|
-- Add moorage entry to process queue for further processing
|
||||||
INSERT INTO process_queue (channel, payload, stored) values ('new_moorage', stay_id, now());
|
INSERT INTO process_queue (channel, payload, stored)
|
||||||
|
VALUES ('new_moorage', stay_id, now());
|
||||||
ELSE
|
ELSE
|
||||||
RAISE WARNING 'Metrics Invalid stay_id [%] [%]', stay_id, NEW.time;
|
RAISE WARNING 'Metrics Invalid stay_id [%] [%]', stay_id, NEW.time;
|
||||||
END IF;
|
END IF;
|
||||||
@@ -505,7 +512,8 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
|
|||||||
VALUES (NEW.client_id, true, NEW.time, NEW.latitude, NEW.longitude, stay_code)
|
VALUES (NEW.client_id, true, NEW.time, NEW.latitude, NEW.longitude, stay_code)
|
||||||
RETURNING id INTO stay_id;
|
RETURNING id INTO stay_id;
|
||||||
-- Add stay entry to process queue for further processing
|
-- Add stay entry to process queue for further processing
|
||||||
INSERT INTO process_queue (channel, payload, stored) values ('new_stay', stay_id, now());
|
INSERT INTO process_queue (channel, payload, stored)
|
||||||
|
VALUES ('new_stay', stay_id, now());
|
||||||
ELSE
|
ELSE
|
||||||
RAISE WARNING 'Metrics Invalid stay_id [%] [%]', stay_id, NEW.time;
|
RAISE WARNING 'Metrics Invalid stay_id [%] [%]', stay_id, NEW.time;
|
||||||
UPDATE api.stays
|
UPDATE api.stays
|
||||||
@@ -520,7 +528,7 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
|
|||||||
logbook_id := public.trip_in_progress_fn(NEW.client_id::TEXT);
|
logbook_id := public.trip_in_progress_fn(NEW.client_id::TEXT);
|
||||||
IF logbook_id IS NOT NULL THEN
|
IF logbook_id IS NOT NULL THEN
|
||||||
-- todo check on time start vs end
|
-- todo check on time start vs end
|
||||||
RAISE WARNING 'Metrics Updating trip status [%] [%] [%]', logbook_id, NEW.status, NEW.time;
|
RAISE WARNING 'Metrics Updating logbook status [%] [%] [%]', logbook_id, NEW.status, NEW.time;
|
||||||
UPDATE api.logbook
|
UPDATE api.logbook
|
||||||
SET
|
SET
|
||||||
active = false,
|
active = false,
|
||||||
@@ -529,7 +537,8 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
|
|||||||
_to_lng = NEW.longitude
|
_to_lng = NEW.longitude
|
||||||
WHERE id = logbook_id;
|
WHERE id = logbook_id;
|
||||||
-- Add logbook entry to process queue for later processing
|
-- Add logbook entry to process queue for later processing
|
||||||
INSERT INTO process_queue (channel, payload, stored) values ('new_logbook', logbook_id, now());
|
INSERT INTO process_queue (channel, payload, stored)
|
||||||
|
VALUEs ('new_logbook', logbook_id, now());
|
||||||
ELSE
|
ELSE
|
||||||
RAISE WARNING 'Metrics Invalid logbook_id [%] [%]', logbook_id, NEW.time;
|
RAISE WARNING 'Metrics Invalid logbook_id [%] [%]', logbook_id, NEW.time;
|
||||||
END IF;
|
END IF;
|
||||||
@@ -627,50 +636,24 @@ COMMENT ON FUNCTION
|
|||||||
-- export_logbook_geojson_fn
|
-- export_logbook_geojson_fn
|
||||||
DROP FUNCTION IF EXISTS api.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 JSON) RETURNS JSON AS $export_logbook_geojson$
|
CREATE FUNCTION api.export_logbook_geojson_fn(IN _id integer, OUT geojson JSON) RETURNS JSON AS $export_logbook_geojson$
|
||||||
|
-- validate with geojson.io
|
||||||
DECLARE
|
DECLARE
|
||||||
logbook_rec record;
|
logbook_rec record;
|
||||||
log_geojson jsonb;
|
|
||||||
metrics_geojson jsonb;
|
|
||||||
_map jsonb;
|
|
||||||
BEGIN
|
BEGIN
|
||||||
-- Gather log details
|
|
||||||
-- If _id is is not NULL and > 0
|
-- 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
|
SELECT * INTO logbook_rec
|
||||||
FROM api.logbook WHERE id = _id;
|
FROM api.logbook WHERE id = _id;
|
||||||
-- GeoJson Feature Logbook linestring
|
-- Ensure the query is successful
|
||||||
SELECT
|
IF logbook_rec.client_id IS NULL THEN
|
||||||
ST_AsGeoJSON(l.*) into log_geojson
|
RAISE WARNING '-> export_logbook_geojson_fn invalid logbook %', _id;
|
||||||
FROM
|
RETURN;
|
||||||
api.logbook l
|
END IF;
|
||||||
WHERE l.id = _id;
|
geojson := logbook_rec.track_geojson;
|
||||||
-- GeoJson Feature Metrics point
|
|
||||||
SELECT
|
|
||||||
json_agg(ST_AsGeoJSON(t.*)::json) into metrics_geojson
|
|
||||||
FROM (
|
|
||||||
( SELECT
|
|
||||||
time,
|
|
||||||
courseovergroundtrue,
|
|
||||||
speedoverground,
|
|
||||||
anglespeedapparent,
|
|
||||||
longitude,latitude,
|
|
||||||
st_makepoint(longitude,latitude) AS geo_point
|
|
||||||
FROM api.metrics m
|
|
||||||
WHERE m.latitude IS NOT NULL
|
|
||||||
AND m.longitude IS NOT NULL
|
|
||||||
AND time >= logbook_rec._from_time::TIMESTAMP WITHOUT TIME ZONE
|
|
||||||
AND time <= logbook_rec._to_time::TIMESTAMP WITHOUT TIME ZONE
|
|
||||||
ORDER BY m.time ASC
|
|
||||||
)
|
|
||||||
) AS t;
|
|
||||||
|
|
||||||
-- Merge jsonb
|
|
||||||
select log_geojson::jsonb || metrics_geojson::jsonb into _map;
|
|
||||||
-- output
|
|
||||||
SELECT
|
|
||||||
json_build_object(
|
|
||||||
'type', 'FeatureCollection',
|
|
||||||
'features', _map
|
|
||||||
) into geojson;
|
|
||||||
END;
|
END;
|
||||||
$export_logbook_geojson$ LANGUAGE plpgsql;
|
$export_logbook_geojson$ LANGUAGE plpgsql;
|
||||||
-- Description
|
-- Description
|
||||||
@@ -687,11 +670,21 @@ AS $export_logbook_gpx$
|
|||||||
DECLARE
|
DECLARE
|
||||||
log_rec record;
|
log_rec record;
|
||||||
BEGIN
|
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 _from_time and _to_time
|
-- Gather log details _from_time and _to_time
|
||||||
SELECT * into log_rec
|
SELECT * INTO log_rec
|
||||||
FROM
|
FROM
|
||||||
api.logbook l
|
api.logbook l
|
||||||
WHERE l.id = _id;
|
WHERE l.id = _id;
|
||||||
|
-- Ensure the query is successful
|
||||||
|
IF log_rec.client_id IS NULL THEN
|
||||||
|
RAISE WARNING '-> export_logbook_gpx_fn invalid logbook %', _id;
|
||||||
|
RETURN '';
|
||||||
|
END IF;
|
||||||
-- Generate XML
|
-- Generate XML
|
||||||
RETURN xmlelement(name gpx,
|
RETURN xmlelement(name gpx,
|
||||||
xmlattributes( '1.1' as version,
|
xmlattributes( '1.1' as version,
|
||||||
@@ -717,10 +710,13 @@ AS $export_logbook_gpx$
|
|||||||
xmlelement(name time, time)
|
xmlelement(name time, time)
|
||||||
)))))::pg_catalog.xml
|
)))))::pg_catalog.xml
|
||||||
FROM api.metrics m
|
FROM api.metrics m
|
||||||
WHERE m.latitude IS NOT null
|
WHERE m.latitude IS NOT NULL
|
||||||
AND m.longitude IS NOT null
|
AND m.longitude IS NOT NULL
|
||||||
AND m.time >= log_rec._from_time::TIMESTAMP WITHOUT TIME ZONE
|
AND m.time >= log_rec._from_time::TIMESTAMP WITHOUT TIME ZONE
|
||||||
AND m.time <= log_rec._to_time::TIMESTAMP WITHOUT TIME ZONE;
|
AND m.time <= log_rec._to_time::TIMESTAMP WITHOUT TIME ZONE
|
||||||
|
AND client_id = log_rec.client_id;
|
||||||
|
-- ERROR: column "m.time" must appear in the GROUP BY clause or be used in an aggregate function at character 2304
|
||||||
|
--ORDER BY m.time ASC;
|
||||||
END;
|
END;
|
||||||
$export_logbook_gpx$ LANGUAGE plpgsql;
|
$export_logbook_gpx$ LANGUAGE plpgsql;
|
||||||
-- Description
|
-- Description
|
||||||
@@ -730,7 +726,7 @@ COMMENT ON FUNCTION
|
|||||||
|
|
||||||
-- Find all log from and to moorage geopoint within 100m
|
-- Find all log from and to moorage geopoint within 100m
|
||||||
DROP FUNCTION IF EXISTS api.find_log_from_moorage_fn;
|
DROP FUNCTION IF EXISTS api.find_log_from_moorage_fn;
|
||||||
CREATE FUNCTION api.find_log_from_moorage_fn(IN _id INTEGER) RETURNS void AS $find_log_from_moorage$
|
CREATE OR REPLACE FUNCTION api.find_log_from_moorage_fn(IN _id INTEGER) RETURNS void AS $find_log_from_moorage$
|
||||||
DECLARE
|
DECLARE
|
||||||
moorage_rec record;
|
moorage_rec record;
|
||||||
logbook_rec record;
|
logbook_rec record;
|
||||||
@@ -763,7 +759,7 @@ COMMENT ON FUNCTION
|
|||||||
|
|
||||||
-- Find all stay within 100m of moorage geopoint
|
-- Find all stay within 100m of moorage geopoint
|
||||||
DROP FUNCTION IF EXISTS api.find_stay_from_moorage_fn;
|
DROP FUNCTION IF EXISTS api.find_stay_from_moorage_fn;
|
||||||
CREATE FUNCTION api.find_stay_from_moorage_fn(IN _id INTEGER) RETURNS void AS $find_stay_from_moorage$
|
CREATE OR REPLACE FUNCTION api.find_stay_from_moorage_fn(IN _id INTEGER) RETURNS void AS $find_stay_from_moorage$
|
||||||
DECLARE
|
DECLARE
|
||||||
moorage_rec record;
|
moorage_rec record;
|
||||||
stay_rec record;
|
stay_rec record;
|
||||||
@@ -832,6 +828,31 @@ COMMENT ON FUNCTION
|
|||||||
public.stay_in_progress_fn
|
public.stay_in_progress_fn
|
||||||
IS 'stay_in_progress';
|
IS 'stay_in_progress';
|
||||||
|
|
||||||
|
-- stay_in_progress_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';
|
||||||
---------------------------------------------------------------------------
|
---------------------------------------------------------------------------
|
||||||
-- API helper views
|
-- API helper views
|
||||||
--
|
--
|
||||||
@@ -869,7 +890,7 @@ CREATE VIEW stay_in_progress AS
|
|||||||
-- TODO: Use materialized views instead as it is not live data
|
-- TODO: Use materialized views instead as it is not live data
|
||||||
-- Logs web view
|
-- Logs web view
|
||||||
DROP VIEW IF EXISTS api.logs_view;
|
DROP VIEW IF EXISTS api.logs_view;
|
||||||
CREATE OR REPLACE VIEW api.logs_view AS
|
CREATE OR REPLACE VIEW api.logs_view WITH (security_invoker=true,security_barrier=true) AS
|
||||||
SELECT id,
|
SELECT id,
|
||||||
name as "Name",
|
name as "Name",
|
||||||
_from as "From",
|
_from as "From",
|
||||||
@@ -886,8 +907,22 @@ COMMENT ON VIEW
|
|||||||
api.logs_view
|
api.logs_view
|
||||||
IS 'Logs web view';
|
IS 'Logs web view';
|
||||||
|
|
||||||
|
-- Inital try of MATERIALIZED VIEW
|
||||||
|
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 api.logbook l
|
||||||
|
WHERE _to_time IS NOT NULL
|
||||||
|
ORDER BY _from_time DESC;
|
||||||
|
|
||||||
DROP VIEW IF EXISTS api.log_view;
|
DROP VIEW IF EXISTS api.log_view;
|
||||||
CREATE OR REPLACE VIEW api.log_view AS
|
CREATE OR REPLACE VIEW api.log_view WITH (security_invoker=true,security_barrier=true) AS
|
||||||
SELECT id,
|
SELECT id,
|
||||||
name as "Name",
|
name as "Name",
|
||||||
_from as "From",
|
_from as "From",
|
||||||
@@ -912,8 +947,8 @@ COMMENT ON VIEW
|
|||||||
-- Stays web view
|
-- Stays web view
|
||||||
-- TODO group by month
|
-- TODO group by month
|
||||||
DROP VIEW IF EXISTS api.stays_view;
|
DROP VIEW IF EXISTS api.stays_view;
|
||||||
CREATE VIEW api.stays_view AS -- TODO
|
CREATE VIEW api.stays_view WITH (security_invoker=true,security_barrier=true) AS -- TODO
|
||||||
SELECT
|
SELECT id,
|
||||||
concat(
|
concat(
|
||||||
extract(DAYS FROM (s.departed-s.arrived)::interval),
|
extract(DAYS FROM (s.departed-s.arrived)::interval),
|
||||||
' days',
|
' days',
|
||||||
@@ -928,7 +963,7 @@ CREATE VIEW api.stays_view AS -- TODO
|
|||||||
s.name AS Moorage,
|
s.name AS Moorage,
|
||||||
s.arrived AS Arrived,
|
s.arrived AS Arrived,
|
||||||
s.departed AS Departed,
|
s.departed AS Departed,
|
||||||
sa.description AS "Stayed at",
|
sa.description AS Stayed_at,
|
||||||
(s.departed-s.arrived) AS Duration
|
(s.departed-s.arrived) AS Duration
|
||||||
FROM api.stays s, api.stays_at sa
|
FROM api.stays s, api.stays_at sa
|
||||||
WHERE departed is not null
|
WHERE departed is not null
|
||||||
@@ -941,8 +976,8 @@ COMMENT ON VIEW
|
|||||||
IS 'Stays web view';
|
IS 'Stays web view';
|
||||||
|
|
||||||
DROP VIEW IF EXISTS api.stay_view;
|
DROP VIEW IF EXISTS api.stay_view;
|
||||||
CREATE VIEW api.stay_view AS -- TODO missing arrival/departured from
|
CREATE VIEW api.stay_view WITH (security_invoker=true,security_barrier=true) AS -- TODO missing arrival/departured from
|
||||||
SELECT
|
SELECT id,
|
||||||
concat(
|
concat(
|
||||||
extract(DAYS FROM (s.departed-s.arrived)::interval),
|
extract(DAYS FROM (s.departed-s.arrived)::interval),
|
||||||
' days',
|
' days',
|
||||||
@@ -988,34 +1023,34 @@ COMMENT ON VIEW
|
|||||||
|
|
||||||
-- the good way?
|
-- the good way?
|
||||||
DROP VIEW IF EXISTS api.moorages_view;
|
DROP VIEW IF EXISTS api.moorages_view;
|
||||||
CREATE OR REPLACE VIEW api.moorages_view AS -- TODO
|
CREATE OR REPLACE VIEW api.moorages_view WITH (security_invoker=true,security_barrier=true) AS -- TODO
|
||||||
SELECT
|
SELECT m.id,
|
||||||
m.name AS Moorage,
|
m.name AS Moorage,
|
||||||
sa.description AS "Default Stay",
|
sa.description AS Default_Stay,
|
||||||
EXTRACT(DAY FROM justify_hours ( m.stay_duration )) AS "Total Stay",
|
EXTRACT(DAY FROM justify_hours ( m.stay_duration )) AS Total_Stay, -- in days
|
||||||
m.reference_count AS "Arrivals & Departures",
|
m.reference_count AS Arrivals_Departures,
|
||||||
m.geog
|
m.geog
|
||||||
-- m.stay_duration,
|
-- m.stay_duration,
|
||||||
-- justify_hours ( m.stay_duration )
|
-- justify_hours ( m.stay_duration )
|
||||||
FROM api.moorages m, api.stays_at sa
|
FROM api.moorages m, api.stays_at sa
|
||||||
WHERE m.name is not null
|
WHERE m.name is not null
|
||||||
AND m.stay_code = sa.stay_code
|
AND m.stay_code = sa.stay_code
|
||||||
GROUP BY m.name,sa.description,m.stay_duration,m.reference_count,m.geog
|
GROUP BY m.id,m.name,sa.description,m.stay_duration,m.reference_count,m.geog
|
||||||
-- ORDER BY 4 DESC;
|
-- ORDER BY 4 DESC;
|
||||||
ORDER BY m.reference_count DESC;
|
ORDER BY m.reference_count DESC;
|
||||||
-- Description
|
-- Description
|
||||||
COMMENT ON VIEW
|
COMMENT ON VIEW
|
||||||
api.moorages_view
|
api.moorages_view
|
||||||
IS 'Moorages web view';
|
IS 'Moorages listing web view';
|
||||||
|
|
||||||
DROP VIEW IF EXISTS api.moorage_view;
|
DROP VIEW IF EXISTS api.moorage_view;
|
||||||
CREATE OR REPLACE VIEW api.moorage_view AS -- TODO
|
CREATE OR REPLACE VIEW api.moorage_view WITH (security_invoker=true,security_barrier=true) AS -- TODO
|
||||||
SELECT
|
SELECT id,
|
||||||
m.name AS "Preferred Name",
|
m.name AS Name,
|
||||||
m.stay_code AS "Default Stay Type",
|
m.stay_code AS Default_Stay,
|
||||||
m.home_flag AS "Home",
|
m.home_flag AS Home,
|
||||||
EXTRACT(DAY FROM justify_hours ( m.stay_duration )) AS "Total Stay",
|
EXTRACT(DAY FROM justify_hours ( m.stay_duration )) AS Total_Stay,
|
||||||
m.reference_count AS "Arrivals & Departures",
|
m.reference_count AS Arrivals_Departures,
|
||||||
m.notes,
|
m.notes,
|
||||||
m.geog
|
m.geog
|
||||||
FROM api.moorages m
|
FROM api.moorages m
|
||||||
@@ -1023,7 +1058,7 @@ CREATE OR REPLACE VIEW api.moorage_view AS -- TODO
|
|||||||
-- Description
|
-- Description
|
||||||
COMMENT ON VIEW
|
COMMENT ON VIEW
|
||||||
api.moorage_view
|
api.moorage_view
|
||||||
IS 'Moorage web view';
|
IS 'Moorage details web view';
|
||||||
|
|
||||||
-- All moorage in 100 meters from the start of a logbook.
|
-- All moorage in 100 meters from the start of a logbook.
|
||||||
-- ST_DistanceSphere Returns minimum distance in meters between two lon/lat points.
|
-- ST_DistanceSphere Returns minimum distance in meters between two lon/lat points.
|
||||||
@@ -1049,7 +1084,7 @@ COMMENT ON VIEW
|
|||||||
----> select sum(l.duration) as "Total Time Underway" from api.logbook l;
|
----> select sum(l.duration) as "Total Time Underway" from api.logbook l;
|
||||||
-- Longest Nonstop Sail from logbook, eg longest trip duration and distance
|
-- Longest Nonstop Sail from logbook, eg longest trip duration and distance
|
||||||
----> select max(l.duration),max(l.distance) from api.logbook l;
|
----> select max(l.duration),max(l.distance) from api.logbook l;
|
||||||
CREATE VIEW api.stats_logs_view AS -- TODO
|
CREATE VIEW api.stats_logs_view WITH (security_invoker=true,security_barrier=true) AS -- TODO
|
||||||
WITH
|
WITH
|
||||||
meta AS (
|
meta AS (
|
||||||
SELECT m.name FROM api.metadata m ),
|
SELECT m.name FROM api.metadata m ),
|
||||||
@@ -1088,7 +1123,7 @@ COMMENT ON VIEW
|
|||||||
----> select sum(m.stay_duration) as "Time Spent Away" from api.moorages m where home_flag is false;
|
----> 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)
|
-- 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;
|
----> 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 VIEW api.stats_moorages_view AS -- TODO
|
CREATE VIEW api.stats_moorages_view WITH (security_invoker=true,security_barrier=true) AS -- TODO
|
||||||
WITH
|
WITH
|
||||||
home_ports AS (
|
home_ports AS (
|
||||||
select count(*) as home_ports from api.moorages m where home_flag is true
|
select count(*) as home_ports from api.moorages m where home_flag is true
|
||||||
@@ -1112,7 +1147,7 @@ COMMENT ON VIEW
|
|||||||
api.stats_moorages_view
|
api.stats_moorages_view
|
||||||
IS 'Statistics Moorages web view';
|
IS 'Statistics Moorages web view';
|
||||||
|
|
||||||
CREATE VIEW api.stats_moorages_away_view AS -- TODO
|
CREATE 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
|
SELECT sa.description,sum(m.stay_duration) as time_spent_away_by
|
||||||
FROM api.moorages m, api.stays_at sa
|
FROM api.moorages m, api.stays_at sa
|
||||||
WHERE home_flag IS false
|
WHERE home_flag IS false
|
||||||
@@ -1133,17 +1168,20 @@ COMMENT ON VIEW
|
|||||||
-- l.*,
|
-- l.*,
|
||||||
-- m.*
|
-- m.*
|
||||||
-- FROM logs l, moorages m;
|
-- FROM logs l, moorages m;
|
||||||
|
--COMMENT ON VIEW
|
||||||
|
-- api.stats_moorages_away_view
|
||||||
|
-- IS 'Statistics Moorages Time Spent Away web view';
|
||||||
|
|
||||||
-- global timelapse
|
-- global timelapse
|
||||||
-- TODO
|
-- TODO
|
||||||
CREATE VIEW timelapse AS -- TODO
|
CREATE VIEW timelapse AS -- TODO
|
||||||
SELECT latitude, longitude from api.metrics;
|
SELECT latitude, longitude from api.metrics;
|
||||||
|
|
||||||
-- View main monitoring for grafana
|
-- View main monitoring for web app
|
||||||
-- LAST Monitoring data from json!
|
CREATE VIEW api.monitoring_view WITH (security_invoker=true,security_barrier=true) AS
|
||||||
CREATE VIEW api.monitoring_view AS
|
|
||||||
SELECT
|
SELECT
|
||||||
time AS "time",
|
time AS "time",
|
||||||
|
(NOW() AT TIME ZONE 'UTC' - time) > INTERVAL '70 MINUTES' as offline,
|
||||||
metrics-> 'environment.water.temperature' AS waterTemperature,
|
metrics-> 'environment.water.temperature' AS waterTemperature,
|
||||||
metrics-> 'environment.inside.temperature' AS insideTemperature,
|
metrics-> 'environment.inside.temperature' AS insideTemperature,
|
||||||
metrics-> 'environment.outside.temperature' AS outsideTemperature,
|
metrics-> 'environment.outside.temperature' AS outsideTemperature,
|
||||||
@@ -1152,9 +1190,21 @@ CREATE VIEW api.monitoring_view AS
|
|||||||
metrics-> 'environment.inside.humidity' AS insideHumidity,
|
metrics-> 'environment.inside.humidity' AS insideHumidity,
|
||||||
metrics-> 'environment.outside.humidity' AS outsideHumidity,
|
metrics-> 'environment.outside.humidity' AS outsideHumidity,
|
||||||
metrics-> 'environment.outside.pressure' AS outsidePressure,
|
metrics-> 'environment.outside.pressure' AS outsidePressure,
|
||||||
metrics-> 'environment.inside.pressure' AS insidePressure
|
metrics-> 'environment.inside.pressure' AS insidePressure,
|
||||||
|
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
|
||||||
|
)::jsonb ) AS geojson,
|
||||||
|
current_setting('vessel.name', false) AS name
|
||||||
FROM api.metrics m
|
FROM api.metrics m
|
||||||
ORDER BY time DESC LIMIT 1;
|
ORDER BY time DESC LIMIT 1;
|
||||||
|
COMMENT ON VIEW
|
||||||
|
api.monitoring_view
|
||||||
|
IS 'Monitoring web view';
|
||||||
|
|
||||||
CREATE VIEW api.monitoring_humidity AS
|
CREATE VIEW api.monitoring_humidity AS
|
||||||
SELECT
|
SELECT
|
||||||
@@ -1193,3 +1243,15 @@ CREATE VIEW api.monitoring_voltage AS
|
|||||||
cast(metrics-> 'electrical.batteries.victronDevice.voltage' AS numeric) AS victronDeviceVoltage
|
cast(metrics-> 'electrical.batteries.victronDevice.voltage' AS numeric) AS victronDeviceVoltage
|
||||||
FROM api.metrics m
|
FROM api.metrics m
|
||||||
ORDER BY time DESC LIMIT 1;
|
ORDER BY time DESC LIMIT 1;
|
||||||
|
|
||||||
|
-- Infotiles web app
|
||||||
|
CREATE OR REPLACE 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 'Monitoring web view';
|
@@ -61,32 +61,32 @@ INSERT INTO email_templates VALUES
|
|||||||
'Welcome',
|
'Welcome',
|
||||||
E'Hello __RECIPIENT__,\nCongratulations!\nYou successfully created an account.\nKeep in mind to register your vessel.\nHappy sailing!',
|
E'Hello __RECIPIENT__,\nCongratulations!\nYou successfully created an account.\nKeep in mind to register your vessel.\nHappy sailing!',
|
||||||
'Welcome',
|
'Welcome',
|
||||||
E'Hi!\nYou successfully created an account\nKeep in mind to register your vessel.\nHappy sailing!'),
|
E'Hi!\nYou successfully created an account\nKeep in mind to register your vessel.\n'),
|
||||||
('new_vessel',
|
('new_vessel',
|
||||||
'New vessel',
|
'New vessel',
|
||||||
E'Hi!\nHow are you?\n__BOAT__ is now linked to your account.',
|
E'Hi!\nHow are you?\n__BOAT__ is now linked to your account.\n',
|
||||||
'New vessel',
|
'New vessel',
|
||||||
E'Hi!\nHow are you?\n__BOAT__ is now linked to your account.'),
|
E'Hi!\nHow are you?\n__BOAT__ is now linked to your account.\n'),
|
||||||
('monitor_offline',
|
('monitor_offline',
|
||||||
'Vessel Offline',
|
'Vessel Offline',
|
||||||
E'__BOAT__ has been offline for more than an hour\r\nFind more details at __APP_URL__/boats/\n',
|
E'__BOAT__ has been offline for more than an hour\r\nFind more details at __APP_URL__/boats\n',
|
||||||
'Vessel Offline',
|
'Vessel Offline',
|
||||||
E'__BOAT__ has been offline for more than an hour\r\nFind more details at __APP_URL__/boats/\n'),
|
E'__BOAT__ has been offline for more than an hour\r\nFind more details at __APP_URL__/boats\n'),
|
||||||
('monitor_online',
|
('monitor_online',
|
||||||
'Vessel Online',
|
'Vessel Online',
|
||||||
E'__BOAT__ just came online\nFind more details at __APP_URL__/boats/\n',
|
E'__BOAT__ just came online\nFind more details at __APP_URL__/boats\n',
|
||||||
'Vessel Online',
|
'Vessel Online',
|
||||||
E'__BOAT__ just came online\nFind more details at __APP_URL__/boats/\n'),
|
E'__BOAT__ just came online\nFind more details at __APP_URL__/boats\n'),
|
||||||
('new_badge',
|
('new_badge',
|
||||||
'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',
|
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!',
|
'New Badge!',
|
||||||
E'Congratulations!\nYou have just unlocked a new badge: __BADGE_NAME__\nSee more details at __APP_URL__/badges\nHappy sailing!\nThe PostgSail Team'),
|
E'Congratulations!\nYou have just unlocked a new badge: __BADGE_NAME__\nSee more details at __APP_URL__/badges\n'),
|
||||||
('pushover_valid',
|
('pushover_valid',
|
||||||
'Pushover integration',
|
'Pushover integration',
|
||||||
E'Hello __RECIPIENT__,\nCongratulations! You have just connect your account to Pushover.\n\nThe PostgSail Team',
|
E'Hello __RECIPIENT__,\nCongratulations! You have just connect your account to Pushover.\n\nThe PostgSail Team',
|
||||||
'Pushover integration!',
|
'Pushover integration!',
|
||||||
E'Congratulations!\nYou have just connect your account to Pushover.\n\nThe PostgSail Team'),
|
E'Congratulations!\nYou have just connect your account to Pushover.\n'),
|
||||||
('email_otp',
|
('email_otp',
|
||||||
'Email verification',
|
'Email verification',
|
||||||
E'Hello,\nPlease active your account using the following code: __OTP_CODE__.\nThe code is valid 15 minutes.\nThe PostgSail Team',
|
E'Hello,\nPlease active your account using the following code: __OTP_CODE__.\nThe code is valid 15 minutes.\nThe PostgSail Team',
|
||||||
@@ -96,22 +96,22 @@ INSERT INTO email_templates VALUES
|
|||||||
'Email verified',
|
'Email verified',
|
||||||
E'Hello __RECIPIENT__,\nCongratulations!\nYou successfully validate your account.\nThe PostgSail Team',
|
E'Hello __RECIPIENT__,\nCongratulations!\nYou successfully validate your account.\nThe PostgSail Team',
|
||||||
'Email verified',
|
'Email verified',
|
||||||
E'Hi!\nYou successfully validate your account.\nHappy sailing!'),
|
E'Hi!\nYou successfully validate your account.\n'),
|
||||||
('email_reset',
|
('email_reset',
|
||||||
'Password reset',
|
'Password reset',
|
||||||
E'Hello,\nYou requested a password reset. To reset your password __APP_URL__/reset?__RESET_QS__.\nThe PostgSail Team',
|
E'Hello,\nYou requested a password reset. To reset your password __APP_URL__/reset?__RESET_QS__.\nThe PostgSail Team',
|
||||||
'Password reset',
|
'Password reset',
|
||||||
E'You requested a password recovery. Check your email!'),
|
E'You requested a password recovery. Check your email!\n'),
|
||||||
('telegram_otp',
|
('telegram_otp',
|
||||||
'Telegram bot',
|
'Telegram bot',
|
||||||
E'Hello __RECIPIENT__,\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.\nThe PostgSail Team',
|
E'Hello __RECIPIENT__,\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.\nThe PostgSail Team',
|
||||||
'Telegram bot',
|
'Telegram bot',
|
||||||
E'Congratulations!\nTo connect your account to a @postgsail_bot. Check your email!'),
|
E'Congratulations!\nTo connect your account to a @postgsail_bot. Check your email!\n'),
|
||||||
('telegram_valid',
|
('telegram_valid',
|
||||||
'Telegram bot',
|
'Telegram bot',
|
||||||
E'Hello __RECIPIENT__,\nCongratulations! You have just connect your account to your vessel, @postgsail_bot.\n\nThe PostgSail Team',
|
E'Hello __RECIPIENT__,\nCongratulations! You have just connect your account to your vessel, @postgsail_bot.\n\nThe PostgSail Team',
|
||||||
'Telegram bot!',
|
'Telegram bot!',
|
||||||
E'Congratulations!\nYou have just connect your account to your vessel, @postgsail_bot.\n\nHappy sailing!\nThe PostgSail Team');
|
E'Congratulations!\nYou have just connect your account to your vessel, @postgsail_bot.\n');
|
||||||
|
|
||||||
---------------------------------------------------------------------------
|
---------------------------------------------------------------------------
|
||||||
-- Queue handling
|
-- Queue handling
|
||||||
|
@@ -15,6 +15,33 @@ CREATE SCHEMA IF NOT EXISTS public;
|
|||||||
-- process single cron event, process_[logbook|stay|moorage|badge]_queue_fn()
|
-- process single cron event, process_[logbook|stay|moorage|badge]_queue_fn()
|
||||||
--
|
--
|
||||||
|
|
||||||
|
CREATE OR REPLACE FUNCTION logbook_metrics_dwithin_fn(
|
||||||
|
IN _start text,
|
||||||
|
IN _end text,
|
||||||
|
IN lgn float,
|
||||||
|
IN lat float,
|
||||||
|
OUT count_metric numeric) AS $logbook_metrics_dwithin$
|
||||||
|
BEGIN
|
||||||
|
SELECT count(*) INTO count_metric
|
||||||
|
FROM api.metrics m
|
||||||
|
WHERE
|
||||||
|
m.latitude IS NOT NULL
|
||||||
|
AND m.longitude IS NOT NULL
|
||||||
|
AND m.time >= _start::TIMESTAMP WITHOUT TIME ZONE
|
||||||
|
AND m.time <= _end::TIMESTAMP WITHOUT TIME ZONE
|
||||||
|
AND client_id = current_setting('vessel.client_id', false)
|
||||||
|
AND ST_DWithin(
|
||||||
|
Geography(ST_MakePoint(m.longitude, m.latitude)),
|
||||||
|
Geography(ST_MakePoint(lgn, lat)),
|
||||||
|
10
|
||||||
|
);
|
||||||
|
END;
|
||||||
|
$logbook_metrics_dwithin$ LANGUAGE plpgsql;
|
||||||
|
-- Description
|
||||||
|
COMMENT ON FUNCTION
|
||||||
|
public.logbook_metrics_dwithin_fn
|
||||||
|
IS 'Check if all entries for a logbook are in stationary movement with 10 meters';
|
||||||
|
|
||||||
-- Update a logbook with avg data
|
-- Update a logbook with avg data
|
||||||
-- TODO using timescale function
|
-- TODO using timescale function
|
||||||
CREATE OR REPLACE FUNCTION logbook_update_avg_fn(
|
CREATE OR REPLACE FUNCTION logbook_update_avg_fn(
|
||||||
@@ -23,25 +50,26 @@ CREATE OR REPLACE FUNCTION logbook_update_avg_fn(
|
|||||||
IN _end TEXT,
|
IN _end TEXT,
|
||||||
OUT avg_speed double precision,
|
OUT avg_speed double precision,
|
||||||
OUT max_speed double precision,
|
OUT max_speed double precision,
|
||||||
OUT max_wind_speed double precision
|
OUT max_wind_speed double precision,
|
||||||
|
OUT count_metric double precision
|
||||||
) AS $logbook_update_avg$
|
) AS $logbook_update_avg$
|
||||||
BEGIN
|
BEGIN
|
||||||
RAISE NOTICE '-> Updating avg for logbook id=%, start:"%", end:"%"', _id, _start, _end;
|
RAISE NOTICE '-> Updating avg for logbook id=%, start:"%", end:"%"', _id, _start, _end;
|
||||||
SELECT AVG(speedoverground), MAX(speedoverground), MAX(windspeedapparent) INTO
|
SELECT AVG(speedoverground), MAX(speedoverground), MAX(windspeedapparent), COUNT(*) INTO
|
||||||
avg_speed, max_speed, max_wind_speed
|
avg_speed, max_speed, max_wind_speed, count_metric
|
||||||
FROM api.metrics m
|
FROM api.metrics m
|
||||||
WHERE m.latitude IS NOT NULL
|
WHERE m.latitude IS NOT NULL
|
||||||
AND m.longitude IS NOT NULL
|
AND m.longitude IS NOT NULL
|
||||||
AND m.time >= _start::TIMESTAMP WITHOUT TIME ZONE
|
AND m.time >= _start::TIMESTAMP WITHOUT TIME ZONE
|
||||||
AND m.time <= _end::TIMESTAMP WITHOUT TIME ZONE
|
AND m.time <= _end::TIMESTAMP WITHOUT TIME ZONE
|
||||||
AND client_id = current_setting('vessel.client_id', false);
|
AND client_id = current_setting('vessel.client_id', false);
|
||||||
RAISE NOTICE '-> Updated avg for logbook id=%, avg_speed:%, max_speed:%, max_wind_speed:%', _id, avg_speed, max_speed, max_wind_speed;
|
RAISE NOTICE '-> Updated avg for logbook id=%, avg_speed:%, max_speed:%, max_wind_speed:%, count:%', _id, avg_speed, max_speed, max_wind_speed, count_metric;
|
||||||
END;
|
END;
|
||||||
$logbook_update_avg$ LANGUAGE plpgsql;
|
$logbook_update_avg$ LANGUAGE plpgsql;
|
||||||
-- Description
|
-- Description
|
||||||
COMMENT ON FUNCTION
|
COMMENT ON FUNCTION
|
||||||
public.logbook_update_avg_fn
|
public.logbook_update_avg_fn
|
||||||
IS 'Update logbook details with calculate average and max data, AVG(speedOverGround), MAX(speedOverGround), MAX(windspeedapparent)';
|
IS 'Update logbook details with calculate average and max data, AVG(speedOverGround), MAX(speedOverGround), MAX(windspeedapparent), count_metric';
|
||||||
|
|
||||||
-- Create a LINESTRING for Geometry
|
-- Create a LINESTRING for Geometry
|
||||||
-- Todo validate st_length unit?
|
-- Todo validate st_length unit?
|
||||||
@@ -91,10 +119,20 @@ CREATE FUNCTION logbook_update_geojson_fn(IN _id integer, IN _start text, IN _en
|
|||||||
begin
|
begin
|
||||||
-- GeoJson Feature Logbook linestring
|
-- GeoJson Feature Logbook linestring
|
||||||
SELECT
|
SELECT
|
||||||
ST_AsGeoJSON(l.*) into log_geojson
|
ST_AsGeoJSON(log.*) into log_geojson
|
||||||
FROM
|
FROM
|
||||||
api.logbook l
|
( select
|
||||||
WHERE l.id = _id;
|
name,
|
||||||
|
distance,
|
||||||
|
duration,
|
||||||
|
avg_speed,
|
||||||
|
avg_speed,
|
||||||
|
max_wind_speed,
|
||||||
|
notes,
|
||||||
|
track_geom
|
||||||
|
FROM api.logbook
|
||||||
|
WHERE id = _id
|
||||||
|
) AS log;
|
||||||
-- GeoJson Feature Metrics point
|
-- GeoJson Feature Metrics point
|
||||||
SELECT
|
SELECT
|
||||||
json_agg(ST_AsGeoJSON(t.*)::json) into metrics_geojson
|
json_agg(ST_AsGeoJSON(t.*)::json) into metrics_geojson
|
||||||
@@ -112,7 +150,7 @@ CREATE FUNCTION logbook_update_geojson_fn(IN _id integer, IN _start text, IN _en
|
|||||||
AND time >= _start::TIMESTAMP WITHOUT TIME ZONE
|
AND time >= _start::TIMESTAMP WITHOUT TIME ZONE
|
||||||
AND time <= _end::TIMESTAMP WITHOUT TIME ZONE
|
AND time <= _end::TIMESTAMP WITHOUT TIME ZONE
|
||||||
AND client_id = current_setting('vessel.client_id', false)
|
AND client_id = current_setting('vessel.client_id', false)
|
||||||
ORDER BY m.time asc
|
ORDER BY m.time ASC
|
||||||
)
|
)
|
||||||
) AS t;
|
) AS t;
|
||||||
|
|
||||||
@@ -131,7 +169,6 @@ COMMENT ON FUNCTION
|
|||||||
public.logbook_update_geojson_fn
|
public.logbook_update_geojson_fn
|
||||||
IS 'Update log details with geojson';
|
IS 'Update log details with geojson';
|
||||||
|
|
||||||
|
|
||||||
-- Update pending new logbook from process queue
|
-- Update pending new logbook from process queue
|
||||||
DROP FUNCTION IF EXISTS process_logbook_queue_fn;
|
DROP FUNCTION IF EXISTS process_logbook_queue_fn;
|
||||||
CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void AS $process_logbook_queue$
|
CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void AS $process_logbook_queue$
|
||||||
@@ -144,9 +181,15 @@ CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void
|
|||||||
geo_rec record;
|
geo_rec record;
|
||||||
log_settings jsonb;
|
log_settings jsonb;
|
||||||
user_settings jsonb;
|
user_settings jsonb;
|
||||||
app_settings jsonb;
|
|
||||||
vessel_settings jsonb;
|
|
||||||
geojson jsonb;
|
geojson jsonb;
|
||||||
|
_invalid_time boolean;
|
||||||
|
_invalid_interval boolean;
|
||||||
|
_invalid_distance boolean;
|
||||||
|
count_metric numeric;
|
||||||
|
previous_stays_id numeric;
|
||||||
|
current_stays_departed text;
|
||||||
|
current_stays_id numeric;
|
||||||
|
current_stays_active boolean;
|
||||||
BEGIN
|
BEGIN
|
||||||
-- If _id is not NULL
|
-- If _id is not NULL
|
||||||
IF _id IS NULL OR _id < 1 THEN
|
IF _id IS NULL OR _id < 1 THEN
|
||||||
@@ -171,20 +214,76 @@ CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void
|
|||||||
PERFORM set_config('vessel.client_id', logbook_rec.client_id, false);
|
PERFORM set_config('vessel.client_id', logbook_rec.client_id, false);
|
||||||
--RAISE WARNING 'public.process_logbook_queue_fn() scheduler vessel.client_id %', current_setting('vessel.client_id', false);
|
--RAISE WARNING 'public.process_logbook_queue_fn() scheduler vessel.client_id %', current_setting('vessel.client_id', false);
|
||||||
|
|
||||||
|
-- Check if all metrics are within 10meters base on geo loc
|
||||||
|
count_metric := logbook_metrics_dwithin_fn(logbook_rec._from_time::TEXT, logbook_rec._to_time::TEXT, logbook_rec._from_lng::NUMERIC, logbook_rec._from_lat::NUMERIC);
|
||||||
|
RAISE NOTICE '-> process_logbook_queue_fn logbook_metrics_dwithin_fn count:[%]', count_metric;
|
||||||
|
|
||||||
|
-- Calculate logbook data average and geo
|
||||||
|
-- Update logbook entry with the latest metric data and calculate data
|
||||||
|
avg_rec := logbook_update_avg_fn(logbook_rec.id, logbook_rec._from_time::TEXT, logbook_rec._to_time::TEXT);
|
||||||
|
geo_rec := logbook_update_geom_distance_fn(logbook_rec.id, logbook_rec._from_time::TEXT, logbook_rec._to_time::TEXT);
|
||||||
|
|
||||||
|
-- Avoid/ignore/delete logbook stationary movement or time sync issue
|
||||||
|
-- Check time start vs end
|
||||||
|
SELECT logbook_rec._to_time::timestamp without time zone < logbook_rec._from_time::timestamp without time zone INTO _invalid_time;
|
||||||
|
-- Is distance is less than 0.010
|
||||||
|
SELECT geo_rec._track_distance < 0.010 INTO _invalid_distance;
|
||||||
|
-- Is duration is less than 100sec
|
||||||
|
SELECT (logbook_rec._to_time::timestamp without time zone - logbook_rec._from_time::timestamp without time zone) < (100::text||' secs')::interval INTO _invalid_interval;
|
||||||
|
-- if stationnary fix data metrics,logbook,stays,moorage
|
||||||
|
IF _invalid_time IS True OR _invalid_distance IS True
|
||||||
|
OR _invalid_distance IS True OR count_metric = avg_rec.count_metric THEN
|
||||||
|
RAISE WARNING '-> process_logbook_queue_fn invalid logbook data [%]', logbook_rec.id;
|
||||||
|
-- Update metrics status to moored
|
||||||
|
UPDATE api.metrics
|
||||||
|
SET status = 'moored'
|
||||||
|
WHERE time >= logbook_rec._from_time::TIMESTAMP WITHOUT TIME ZONE
|
||||||
|
AND time <= logbook_rec._to_time::TIMESTAMP WITHOUT TIME ZONE
|
||||||
|
AND client_id = current_setting('vessel.client_id', false);
|
||||||
|
-- Update logbook
|
||||||
|
UPDATE api.logbook
|
||||||
|
SET notes = 'invalid logbook data, stationary need to fix metrics?'
|
||||||
|
WHERE id = logbook_rec.id;
|
||||||
|
-- Get related stays
|
||||||
|
SELECT id,departed,active INTO current_stays_id,current_stays_departed,current_stays_active
|
||||||
|
FROM api.stays s
|
||||||
|
WHERE s.client_id = current_setting('vessel.client_id', false)
|
||||||
|
AND s.arrived = logbook_rec._to_time;
|
||||||
|
-- Update related stays
|
||||||
|
UPDATE api.stays
|
||||||
|
SET notes = 'invalid stays data, stationary need to fix metrics?'
|
||||||
|
WHERE client_id = current_setting('vessel.client_id', false)
|
||||||
|
AND arrived = logbook_rec._to_time;
|
||||||
|
-- Find previous stays
|
||||||
|
SELECT id INTO previous_stays_id
|
||||||
|
FROM api.stays s
|
||||||
|
WHERE s.client_id = current_setting('vessel.client_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::timestamp without time zone,
|
||||||
|
active = current_stays_active
|
||||||
|
WHERE client_id = current_setting('vessel.client_id', false)
|
||||||
|
AND id = previous_stays_id;
|
||||||
|
-- Clean u, remove invalid logbook and stay entry
|
||||||
|
DELETE FROM api.logbook WHERE id = logbook_rec.id;
|
||||||
|
RAISE WARNING '-> process_logbook_queue_fn delete invalid logbook [%]', logbook_rec.id;
|
||||||
|
DELETE FROM api.stays WHERE id = current_stays_id;
|
||||||
|
RAISE WARNING '-> process_logbook_queue_fn delete invalid stays [%]', current_stays_id;
|
||||||
|
-- TODO should we substract (-1) moorages ref count or reprocess it?!?
|
||||||
|
RETURN;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Generate logbook name, concat _from_location and _to_locacion
|
||||||
-- geo reverse _from_lng _from_lat
|
-- geo reverse _from_lng _from_lat
|
||||||
-- geo reverse _to_lng _to_lat
|
-- geo reverse _to_lng _to_lat
|
||||||
from_name := reverse_geocode_py_fn('nominatim', logbook_rec._from_lng::NUMERIC, logbook_rec._from_lat::NUMERIC);
|
from_name := reverse_geocode_py_fn('nominatim', logbook_rec._from_lng::NUMERIC, logbook_rec._from_lat::NUMERIC);
|
||||||
to_name := reverse_geocode_py_fn('nominatim', logbook_rec._to_lng::NUMERIC, logbook_rec._to_lat::NUMERIC);
|
to_name := reverse_geocode_py_fn('nominatim', logbook_rec._to_lng::NUMERIC, logbook_rec._to_lat::NUMERIC);
|
||||||
SELECT CONCAT(from_name, ' to ' , to_name) INTO log_name;
|
SELECT CONCAT(from_name, ' to ' , to_name) INTO log_name;
|
||||||
-- SELECT CONCAT("_from" , ' to ' ,"_to") from api.logbook where id = 1;
|
|
||||||
|
|
||||||
-- Generate logbook name, concat _from_location and to _to_locacion
|
RAISE NOTICE 'Updating valid logbook entry [%] [%] [%]', logbook_rec.id, logbook_rec._from_time, logbook_rec._to_time;
|
||||||
-- Update logbook entry with the latest metric data and calculate data
|
|
||||||
avg_rec := logbook_update_avg_fn(logbook_rec.id, logbook_rec._from_time::TEXT, logbook_rec._to_time::TEXT);
|
|
||||||
geo_rec := logbook_update_geom_distance_fn(logbook_rec.id, logbook_rec._from_time::TEXT, logbook_rec._to_time::TEXT);
|
|
||||||
--geojson := logbook_update_geojson_fn(logbook_rec.id, logbook_rec._from_time::TEXT, logbook_rec._to_time::TEXT);
|
|
||||||
-- todo check on time start vs end
|
|
||||||
RAISE NOTICE 'Updating logbook entry [%] [%] [%]', logbook_rec.id, logbook_rec._from_time, logbook_rec._to_time;
|
|
||||||
UPDATE api.logbook
|
UPDATE api.logbook
|
||||||
SET
|
SET
|
||||||
duration = (logbook_rec._to_time::timestamp without time zone - logbook_rec._from_time::timestamp without time zone),
|
duration = (logbook_rec._to_time::timestamp without time zone - logbook_rec._from_time::timestamp without time zone),
|
||||||
@@ -198,26 +297,21 @@ CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void
|
|||||||
distance = geo_rec._track_distance
|
distance = geo_rec._track_distance
|
||||||
WHERE id = logbook_rec.id;
|
WHERE id = logbook_rec.id;
|
||||||
|
|
||||||
-- GeoJSON
|
-- GeoJSON require track_geom field
|
||||||
geojson := logbook_update_geojson_fn(logbook_rec.id, logbook_rec._from_time::TEXT, logbook_rec._to_time::TEXT);
|
geojson := logbook_update_geojson_fn(logbook_rec.id, logbook_rec._from_time::TEXT, logbook_rec._to_time::TEXT);
|
||||||
UPDATE api.logbook
|
UPDATE api.logbook
|
||||||
SET
|
SET
|
||||||
track_geojson = geojson
|
track_geojson = geojson
|
||||||
WHERE id = logbook_rec.id;
|
WHERE id = logbook_rec.id;
|
||||||
-- Gather email and pushover app settings
|
|
||||||
app_settings := get_app_settings_fn();
|
-- Prepare notification, gather user settings
|
||||||
-- Gather user settings
|
|
||||||
SELECT json_build_object('logbook_name', log_name, 'logbook_link', logbook_rec.id) into log_settings;
|
SELECT json_build_object('logbook_name', log_name, 'logbook_link', logbook_rec.id) into log_settings;
|
||||||
user_settings := get_user_settings_from_clientid_fn(logbook_rec.client_id::TEXT);
|
user_settings := get_user_settings_from_clientid_fn(logbook_rec.client_id::TEXT);
|
||||||
SELECT user_settings::JSONB || log_settings::JSONB into user_settings;
|
SELECT user_settings::JSONB || log_settings::JSONB into user_settings;
|
||||||
RAISE DEBUG '-> debug process_logbook_queue_fn get_user_settings_from_clientid_fn [%]', user_settings;
|
RAISE DEBUG '-> debug process_logbook_queue_fn get_user_settings_from_clientid_fn [%]', user_settings;
|
||||||
--user_settings := get_user_settings_from_log_fn(logbook_rec::RECORD);
|
RAISE DEBUG '-> debug process_logbook_queue_fn log_settings [%]', log_settings;
|
||||||
--user_settings := '{"logbook_name": "' || log_name || '"}, "{"email": "' || account_rec.email || '", "recipient": "' || account_rec.first || '}';
|
-- Send notification
|
||||||
--user_settings := '{"logbook_name": "' || log_name || '"}';
|
|
||||||
-- Send notification email, pushover
|
|
||||||
PERFORM send_notification_fn('logbook'::TEXT, user_settings::JSONB);
|
PERFORM send_notification_fn('logbook'::TEXT, user_settings::JSONB);
|
||||||
--PERFORM send_email_py_fn('logbook'::TEXT, user_settings::JSONB, app_settings::JSONB);
|
|
||||||
--PERFORM send_pushover_py_fn('logbook'::TEXT, user_settings::JSONB, app_settings::JSONB);
|
|
||||||
END;
|
END;
|
||||||
$process_logbook_queue$ LANGUAGE plpgsql;
|
$process_logbook_queue$ LANGUAGE plpgsql;
|
||||||
-- Description
|
-- Description
|
||||||
@@ -236,6 +330,7 @@ CREATE OR REPLACE FUNCTION process_stay_queue_fn(IN _id integer) RETURNS void AS
|
|||||||
-- If _id is valid, not NULL
|
-- If _id is valid, not NULL
|
||||||
IF _id IS NULL OR _id < 1 THEN
|
IF _id IS NULL OR _id < 1 THEN
|
||||||
RAISE WARNING '-> process_stay_queue_fn invalid input %', _id;
|
RAISE WARNING '-> process_stay_queue_fn invalid input %', _id;
|
||||||
|
RETURN;
|
||||||
END IF;
|
END IF;
|
||||||
-- Get the stay record with all necesary fields exist
|
-- Get the stay record with all necesary fields exist
|
||||||
SELECT * INTO stay_rec
|
SELECT * INTO stay_rec
|
||||||
@@ -281,6 +376,7 @@ CREATE OR REPLACE FUNCTION process_moorage_queue_fn(IN _id integer) RETURNS void
|
|||||||
-- If _id is not NULL
|
-- If _id is not NULL
|
||||||
IF _id IS NULL OR _id < 1 THEN
|
IF _id IS NULL OR _id < 1 THEN
|
||||||
RAISE WARNING '-> process_moorage_queue_fn invalid input %', _id;
|
RAISE WARNING '-> process_moorage_queue_fn invalid input %', _id;
|
||||||
|
RETURN;
|
||||||
END IF;
|
END IF;
|
||||||
-- Get the stay record with all necesary fields exist
|
-- Get the stay record with all necesary fields exist
|
||||||
SELECT * INTO stay_rec
|
SELECT * INTO stay_rec
|
||||||
@@ -291,7 +387,13 @@ CREATE OR REPLACE FUNCTION process_moorage_queue_fn(IN _id integer) RETURNS void
|
|||||||
AND longitude IS NOT NULL
|
AND longitude IS NOT NULL
|
||||||
AND latitude IS NOT NULL
|
AND latitude IS NOT NULL
|
||||||
AND id = _id;
|
AND id = _id;
|
||||||
|
-- Ensure the query is successful
|
||||||
|
IF stay_rec.client_id IS NULL THEN
|
||||||
|
RAISE WARNING '-> process_moorage_queue_fn invalid stay %', _id;
|
||||||
|
RETURN;
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Do we have an existing stay within 100m of the new moorage
|
||||||
FOR moorage_rec in
|
FOR moorage_rec in
|
||||||
SELECT
|
SELECT
|
||||||
*
|
*
|
||||||
@@ -299,6 +401,7 @@ CREATE OR REPLACE FUNCTION process_moorage_queue_fn(IN _id integer) RETURNS void
|
|||||||
WHERE
|
WHERE
|
||||||
latitude IS NOT NULL
|
latitude IS NOT NULL
|
||||||
AND longitude IS NOT NULL
|
AND longitude IS NOT NULL
|
||||||
|
AND geog IS NOT NULL
|
||||||
AND ST_DWithin(
|
AND ST_DWithin(
|
||||||
-- Geography(ST_MakePoint(stay_rec._lng, stay_rec._lat)),
|
-- Geography(ST_MakePoint(stay_rec._lng, stay_rec._lat)),
|
||||||
stay_rec.geog,
|
stay_rec.geog,
|
||||||
@@ -326,7 +429,7 @@ CREATE OR REPLACE FUNCTION process_moorage_queue_fn(IN _id integer) RETURNS void
|
|||||||
moorage_rec.stay_duration +
|
moorage_rec.stay_duration +
|
||||||
(stay_rec.departed::timestamp without time zone - stay_rec.arrived::timestamp without time zone)
|
(stay_rec.departed::timestamp without time zone - stay_rec.arrived::timestamp without time zone)
|
||||||
WHERE id = moorage_rec.id;
|
WHERE id = moorage_rec.id;
|
||||||
else
|
ELSE
|
||||||
RAISE NOTICE 'Insert new moorage entry from stay %', stay_rec;
|
RAISE NOTICE 'Insert new moorage entry from stay %', stay_rec;
|
||||||
-- Ensure the stay as a name if lat,lon
|
-- Ensure the stay as a name if lat,lon
|
||||||
IF stay_rec.name IS NULL AND stay_rec.longitude IS NOT NULL AND stay_rec.latitude IS NOT NULL THEN
|
IF stay_rec.name IS NULL AND stay_rec.longitude IS NOT NULL AND stay_rec.latitude IS NOT NULL THEN
|
||||||
@@ -576,6 +679,7 @@ AS $send_notification$
|
|||||||
telegram_settings JSONB := NULL;
|
telegram_settings JSONB := NULL;
|
||||||
_email TEXT := NULL;
|
_email TEXT := NULL;
|
||||||
BEGIN
|
BEGIN
|
||||||
|
-- TODO input check
|
||||||
--RAISE NOTICE '--> send_notification_fn type [%]', email_type;
|
--RAISE NOTICE '--> send_notification_fn type [%]', email_type;
|
||||||
-- Gather notification app settings, eg: email, pushover, telegram
|
-- Gather notification app settings, eg: email, pushover, telegram
|
||||||
app_settings := get_app_settings_fn();
|
app_settings := get_app_settings_fn();
|
||||||
@@ -766,12 +870,13 @@ BEGIN
|
|||||||
END IF;
|
END IF;
|
||||||
--RAISE WARNING 'req path %', current_setting('request.path', true);
|
--RAISE WARNING 'req path %', current_setting('request.path', true);
|
||||||
-- Function allow without defined vessel
|
-- Function allow without defined vessel
|
||||||
-- openapi doc, user settings and vessel registration
|
-- openapi doc, user settings, otp code and vessel registration
|
||||||
SELECT current_setting('request.path', true) into _path;
|
SELECT current_setting('request.path', true) into _path;
|
||||||
IF _path = '/rpc/settings_fn'
|
IF _path = '/rpc/settings_fn'
|
||||||
OR _path = '/rpc/register_vessel'
|
OR _path = '/rpc/register_vessel'
|
||||||
OR _path = '/rpc/update_user_preferences_fn'
|
OR _path = '/rpc/update_user_preferences_fn'
|
||||||
OR _path = '/rpc/versions_fn'
|
OR _path = '/rpc/versions_fn'
|
||||||
|
OR _path = '/rpc/email_fn'
|
||||||
OR _path = '/' THEN
|
OR _path = '/' THEN
|
||||||
RETURN;
|
RETURN;
|
||||||
END IF;
|
END IF;
|
||||||
@@ -798,18 +903,17 @@ BEGIN
|
|||||||
PERFORM set_config('vessel.id', vessel_rec.vessel_id, false);
|
PERFORM set_config('vessel.id', vessel_rec.vessel_id, false);
|
||||||
PERFORM set_config('vessel.name', vessel_rec.name, false);
|
PERFORM set_config('vessel.name', vessel_rec.name, false);
|
||||||
-- ensure vessel is connected
|
-- ensure vessel is connected
|
||||||
SELECT m.client_id INTO _clientid
|
SELECT coalesce(m.client_id, null) INTO _clientid
|
||||||
FROM auth.vessels v, api.metadata m
|
FROM auth.vessels v, api.metadata m
|
||||||
WHERE
|
WHERE
|
||||||
m.vessel_id = current_setting('vessel.id')
|
m.vessel_id = current_setting('vessel.id')
|
||||||
AND m.vessel_id = v.vessel_id
|
AND m.vessel_id = v.vessel_id
|
||||||
AND v.owner_email =_email;
|
AND v.owner_email =_email;
|
||||||
IF FOUND THEN
|
-- Set session variables
|
||||||
PERFORM set_config('vessel.client_id', _clientid, false);
|
PERFORM set_config('vessel.client_id', _clientid, false);
|
||||||
--RAISE WARNING 'public.check_jwt() user_role vessel.client_id %', current_setting('vessel.client_id', false);
|
--RAISE WARNING 'public.check_jwt() user_role vessel.client_id [%]', current_setting('vessel.client_id', false);
|
||||||
END IF;
|
--RAISE WARNING 'public.check_jwt() user_role vessel.id [%]', current_setting('vessel.id', false);
|
||||||
--RAISE WARNING 'public.check_jwt() user_role vessel.mmsi %', current_setting('vessel.mmsi', false);
|
--RAISE WARNING 'public.check_jwt() user_role vessel.name [%]', current_setting('vessel.name', false);
|
||||||
--RAISE WARNING 'public.check_jwt() user_role vessel.name %', current_setting('vessel.name', false);
|
|
||||||
ELSIF _role = 'vessel_role' THEN
|
ELSIF _role = 'vessel_role' THEN
|
||||||
SELECT current_setting('request.jwt.claims', true)::json->>'vid' INTO _vid;
|
SELECT current_setting('request.jwt.claims', true)::json->>'vid' INTO _vid;
|
||||||
-- Check the vessel and user exist
|
-- Check the vessel and user exist
|
||||||
|
@@ -51,14 +51,26 @@ AS $reverse_geocode_py$
|
|||||||
r_dict = r.json()
|
r_dict = r.json()
|
||||||
if r_dict["name"]:
|
if r_dict["name"]:
|
||||||
return r_dict["name"]
|
return r_dict["name"]
|
||||||
elif "address" in r_dict and r_dict["address"] and r_dict["address"]["road"]:
|
elif "address" in r_dict and r_dict["address"]:
|
||||||
|
if "road" in r_dict["address"] and r_dict["address"]["road"]:
|
||||||
return r_dict["address"]["road"]
|
return r_dict["address"]["road"]
|
||||||
elif "address" in r_dict and r_dict["address"] and r_dict["address"]["neighbourhood"]:
|
elif "neighbourhood" in r_dict["address"] and r_dict["address"]["neighbourhood"]:
|
||||||
return r_dict["address"]["neighbourhood"]
|
return r_dict["address"]["neighbourhood"]
|
||||||
elif "address" in r_dict and r_dict["address"] and r_dict["address"]["suburb"]:
|
elif "suburb" in r_dict["address"] and r_dict["address"]["suburb"]:
|
||||||
return r_dict["address"]["suburb"]
|
return r_dict["address"]["suburb"]
|
||||||
|
elif "residential" in r_dict["address"] and r_dict["address"]["residential"]:
|
||||||
|
return r_dict["address"]["residential"]
|
||||||
|
elif "village" in r_dict["address"] and r_dict["address"]["village"]:
|
||||||
|
return r_dict["address"]["village"]
|
||||||
|
elif "town" in r_dict["address"] and r_dict["address"]["town"]:
|
||||||
|
return r_dict["address"]["town"]
|
||||||
else:
|
else:
|
||||||
plpy.error('Failed to received a geo full address %s', r.json())
|
return 'n/a'
|
||||||
|
else:
|
||||||
|
return 'n/a'
|
||||||
|
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 'unknow'
|
return 'unknow'
|
||||||
$reverse_geocode_py$ LANGUAGE plpython3u;
|
$reverse_geocode_py$ LANGUAGE plpython3u;
|
||||||
-- Description
|
-- Description
|
||||||
@@ -357,3 +369,13 @@ $reverse_geoip_py$ TRANSFORM FOR TYPE jsonb LANGUAGE plpython3u;
|
|||||||
COMMENT ON FUNCTION
|
COMMENT ON FUNCTION
|
||||||
public.reverse_geoip_py_fn
|
public.reverse_geoip_py_fn
|
||||||
IS 'Retrieve reverse geo IP location via ipapi.co using plpython3u';
|
IS 'Retrieve reverse geo IP location via ipapi.co using plpython3u';
|
||||||
|
|
||||||
|
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';
|
||||||
|
@@ -172,6 +172,8 @@ declare
|
|||||||
_role name;
|
_role name;
|
||||||
result auth.jwt_token;
|
result auth.jwt_token;
|
||||||
app_jwt_secret text;
|
app_jwt_secret text;
|
||||||
|
_email_valid boolean := false;
|
||||||
|
_email text := email;
|
||||||
begin
|
begin
|
||||||
-- check email and password
|
-- check email and password
|
||||||
select auth.user_role(email, pass) into _role;
|
select auth.user_role(email, pass) into _role;
|
||||||
@@ -184,6 +186,16 @@ begin
|
|||||||
FROM app_settings
|
FROM app_settings
|
||||||
WHERE name = 'app.jwt_secret';
|
WHERE name = 'app.jwt_secret';
|
||||||
|
|
||||||
|
-- Check email_valid and generate OTP
|
||||||
|
SELECT preferences['email_valid'] INTO _email_valid
|
||||||
|
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)
|
||||||
|
VALUES ('email_otp', email, now());
|
||||||
|
END IF;
|
||||||
|
|
||||||
|
-- Generate jwt
|
||||||
select jwt.sign(
|
select jwt.sign(
|
||||||
-- row_to_json(r), ''
|
-- row_to_json(r), ''
|
||||||
-- row_to_json(r)::json, current_setting('app.jwt_secret')::text
|
-- row_to_json(r)::json, current_setting('app.jwt_secret')::text
|
||||||
|
@@ -22,7 +22,7 @@ CREATE OR REPLACE VIEW api.vessels_view AS
|
|||||||
FROM api.metadata m
|
FROM api.metadata m
|
||||||
WHERE m.vessel_id = current_setting('vessel.id')
|
WHERE m.vessel_id = current_setting('vessel.id')
|
||||||
)::TEXT ,
|
)::TEXT ,
|
||||||
''::TEXT ) as last_contact
|
NULL ) as last_contact
|
||||||
)
|
)
|
||||||
SELECT
|
SELECT
|
||||||
v.name as name,
|
v.name as name,
|
||||||
@@ -42,6 +42,10 @@ CREATE OR REPLACE VIEW api.vessels2_view AS
|
|||||||
FROM auth.vessels v
|
FROM auth.vessels v
|
||||||
LEFT JOIN api.metadata m ON v.owner_email = current_setting('user.email')
|
LEFT JOIN api.metadata m ON v.owner_email = current_setting('user.email')
|
||||||
AND m.vessel_id = current_setting('vessel.id');
|
AND m.vessel_id = current_setting('vessel.id');
|
||||||
|
-- Description
|
||||||
|
COMMENT ON VIEW
|
||||||
|
api.vessels2_view
|
||||||
|
IS 'Expose has vessel pending validation to API - TO DELETE?';
|
||||||
|
|
||||||
DROP VIEW IF EXISTS api.vessel_p_view;
|
DROP VIEW IF EXISTS api.vessel_p_view;
|
||||||
CREATE OR REPLACE VIEW api.vessel_p_view AS
|
CREATE OR REPLACE VIEW api.vessel_p_view AS
|
||||||
@@ -52,6 +56,29 @@ CREATE OR REPLACE VIEW api.vessel_p_view AS
|
|||||||
null as last_contact
|
null as last_contact
|
||||||
FROM auth.vessels v
|
FROM auth.vessels v
|
||||||
WHERE v.owner_email = current_setting('user.email');
|
WHERE v.owner_email = current_setting('user.email');
|
||||||
|
-- Description
|
||||||
|
COMMENT ON VIEW
|
||||||
|
api.vessel_p_view
|
||||||
|
IS 'Expose has vessel pending validation to API - TO DELETE?';
|
||||||
|
|
||||||
|
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 'Expose has vessel to API';
|
||||||
|
|
||||||
-- Or function?
|
-- Or function?
|
||||||
-- TODO Improve: return null until the vessel has sent metadata?
|
-- TODO Improve: return null until the vessel has sent metadata?
|
||||||
@@ -86,6 +113,7 @@ AS $vessel$
|
|||||||
latitude IS NOT NULL
|
latitude IS NOT NULL
|
||||||
AND longitude IS NOT NULL
|
AND longitude IS NOT NULL
|
||||||
AND client_id = current_setting('vessel.client_id', false)
|
AND client_id = current_setting('vessel.client_id', false)
|
||||||
|
ORDER BY time DESC
|
||||||
)
|
)
|
||||||
) AS t
|
) AS t
|
||||||
) AS geojson_t
|
) AS geojson_t
|
||||||
@@ -108,7 +136,8 @@ AS $user_settings$
|
|||||||
select row_to_json(row)::json INTO settings
|
select row_to_json(row)::json INTO settings
|
||||||
from (
|
from (
|
||||||
select email,first,last,preferences,created_at,
|
select email,first,last,preferences,created_at,
|
||||||
INITCAP(CONCAT (LEFT(first, 1), ' ', last)) AS username
|
INITCAP(CONCAT (LEFT(first, 1), ' ', last)) AS username,
|
||||||
|
public.has_vessel_fn() as has_vessel
|
||||||
from auth.accounts
|
from auth.accounts
|
||||||
where email = current_setting('user.email')
|
where email = current_setting('user.email')
|
||||||
) row;
|
) row;
|
||||||
@@ -127,10 +156,10 @@ AS $version$
|
|||||||
_sysv TEXT;
|
_sysv TEXT;
|
||||||
BEGIN
|
BEGIN
|
||||||
SELECT
|
SELECT
|
||||||
value, version() into _appv,_sysv
|
value, rtrim(substring(version(), 0, 17)) AS sys_version into _appv,_sysv
|
||||||
FROM app_settings
|
FROM app_settings
|
||||||
WHERE name = 'app.version';
|
WHERE name = 'app.version';
|
||||||
RETURN json_build_object('app_version', _appv,
|
RETURN json_build_object('api_version', _appv,
|
||||||
'sys_version', _sysv);
|
'sys_version', _sysv);
|
||||||
END;
|
END;
|
||||||
$version$ language plpgsql security definer;
|
$version$ language plpgsql security definer;
|
||||||
@@ -142,8 +171,9 @@ COMMENT ON FUNCTION
|
|||||||
DROP VIEW IF EXISTS api.versions_view;
|
DROP VIEW IF EXISTS api.versions_view;
|
||||||
CREATE OR REPLACE VIEW api.versions_view AS
|
CREATE OR REPLACE VIEW api.versions_view AS
|
||||||
SELECT
|
SELECT
|
||||||
value as app_version,
|
value AS api_version,
|
||||||
version() as sys_version
|
--version() as sys_version
|
||||||
|
rtrim(substring(version(), 0, 17)) AS sys_version
|
||||||
FROM app_settings
|
FROM app_settings
|
||||||
WHERE name = 'app.version';
|
WHERE name = 'app.version';
|
||||||
-- Description
|
-- Description
|
||||||
|
@@ -54,7 +54,7 @@ AS $generate_otp$
|
|||||||
DECLARE
|
DECLARE
|
||||||
_email CITEXT := email;
|
_email CITEXT := email;
|
||||||
_email_check TEXT := NULL;
|
_email_check TEXT := NULL;
|
||||||
otp_pass VARCHAR(10) := NULL;
|
_otp_pass VARCHAR(10) := NULL;
|
||||||
BEGIN
|
BEGIN
|
||||||
IF email IS NULL OR _email IS NULL OR _email = '' THEN
|
IF email IS NULL OR _email IS NULL OR _email = '' THEN
|
||||||
RAISE EXCEPTION 'invalid input' USING HINT = 'check your parameter';
|
RAISE EXCEPTION 'invalid input' USING HINT = 'check your parameter';
|
||||||
@@ -64,9 +64,12 @@ AS $generate_otp$
|
|||||||
RETURN NULL;
|
RETURN NULL;
|
||||||
END IF;
|
END IF;
|
||||||
--SELECT substr(gen_random_uuid()::text, 1, 6) INTO otp_pass;
|
--SELECT substr(gen_random_uuid()::text, 1, 6) INTO otp_pass;
|
||||||
SELECT generate_uid_fn(6) INTO otp_pass;
|
SELECT generate_uid_fn(6) INTO _otp_pass;
|
||||||
INSERT INTO auth.otp (user_email, otp_pass) VALUES (_email_check, otp_pass);
|
-- upsert - Insert or update otp code on conflit
|
||||||
RETURN otp_pass;
|
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;
|
END;
|
||||||
$generate_otp$ language plpgsql security definer;
|
$generate_otp$ language plpgsql security definer;
|
||||||
-- Description
|
-- Description
|
||||||
@@ -239,7 +242,11 @@ COMMENT ON FUNCTION
|
|||||||
api.email_fn
|
api.email_fn
|
||||||
IS 'Store email_valid into user preferences if valid token/otp';
|
IS 'Store email_valid into user preferences if valid token/otp';
|
||||||
|
|
||||||
CREATE OR REPLACE FUNCTION api.pushover_subscribe_link_fn(IN email TEXT, OUT pushover_link JSON) RETURNS JSON
|
-- 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$
|
AS $pushover_subscribe_link$
|
||||||
DECLARE
|
DECLARE
|
||||||
app_url text;
|
app_url text;
|
||||||
@@ -247,11 +254,12 @@ AS $pushover_subscribe_link$
|
|||||||
pushover_app_url text;
|
pushover_app_url text;
|
||||||
success text;
|
success text;
|
||||||
failure text;
|
failure text;
|
||||||
|
email text := current_setting('user.email', true);
|
||||||
BEGIN
|
BEGIN
|
||||||
|
--https://pushover.net/api/subscriptions#web
|
||||||
-- "https://pushover.net/subscribe/PostgSail-23uvrho1d5y6n3e"
|
-- "https://pushover.net/subscribe/PostgSail-23uvrho1d5y6n3e"
|
||||||
-- + "?success=" + urlencode("https://beta.openplotter.cloud/api/rpc/pushover_fn?token=" + generate_otp_fn({{email}}))
|
-- + "?success=" + urlencode("https://beta.openplotter.cloud/api/rpc/pushover_fn?token=" + generate_otp_fn({{email}}))
|
||||||
-- + "&failure=" + urlencode("https://beta.openplotter.cloud/settings");
|
-- + "&failure=" + urlencode("https://beta.openplotter.cloud/settings");
|
||||||
|
|
||||||
-- get app_url
|
-- get app_url
|
||||||
SELECT
|
SELECT
|
||||||
value INTO app_url
|
value INTO app_url
|
||||||
@@ -266,23 +274,28 @@ AS $pushover_subscribe_link$
|
|||||||
public.app_settings
|
public.app_settings
|
||||||
WHERE
|
WHERE
|
||||||
name = 'app.pushover_app_url';
|
name = 'app.pushover_app_url';
|
||||||
|
-- Generate OTP
|
||||||
otp_code := api.generate_otp_fn(email);
|
otp_code := api.generate_otp_fn(email);
|
||||||
-- On sucess redirect to to API endpoing
|
-- On sucess redirect to API endpoint
|
||||||
SELECT CONCAT(
|
SELECT CONCAT(
|
||||||
'?success=',
|
'?success=',
|
||||||
urlencode(CONCAT(app_url,'/api/rpc/pushover_fn?token=')),
|
public.urlescape_py_fn(CONCAT(app_url,'/pushover?token=')),
|
||||||
otp_code)
|
otp_code)
|
||||||
INTO success;
|
INTO success;
|
||||||
-- On failure redirect to user settings, where he does come from
|
-- On failure redirect to user settings, where he does come from
|
||||||
SELECT CONCAT(
|
SELECT CONCAT(
|
||||||
'&failure=',
|
'&failure=',
|
||||||
urlencode(CONCAT(app_url,'/settings'))
|
public.urlescape_py_fn(CONCAT(app_url,'/profile'))
|
||||||
) INTO failure;
|
) INTO failure;
|
||||||
SELECT json_build_object('link', CONCAT(pushover_app_url, success, failure)) INTO pushover_link;
|
SELECT json_build_object('link', CONCAT(pushover_app_url, success, failure)) INTO pushover_link;
|
||||||
END;
|
END;
|
||||||
$pushover_subscribe_link$ language plpgsql security definer;
|
$pushover_subscribe_link$ language plpgsql security definer;
|
||||||
|
-- Description
|
||||||
|
COMMENT ON FUNCTION
|
||||||
|
api.pushover_subscribe_link_fn
|
||||||
|
IS 'Generate Pushover subscription link';
|
||||||
|
|
||||||
-- Pushover Subscription API
|
-- Confirm Pushover Subscription
|
||||||
-- Web-Based Subscription Process
|
-- Web-Based Subscription Process
|
||||||
-- https://pushover.net/api/subscriptions#web
|
-- https://pushover.net/api/subscriptions#web
|
||||||
-- Expose as an API endpoint
|
-- Expose as an API endpoint
|
||||||
@@ -322,7 +335,7 @@ $pushover$ language plpgsql security definer;
|
|||||||
-- Description
|
-- Description
|
||||||
COMMENT ON FUNCTION
|
COMMENT ON FUNCTION
|
||||||
api.pushover_fn
|
api.pushover_fn
|
||||||
IS 'Store pushover_user_key into user preferences if valid token/otp';
|
IS 'Confirm Pushover Subscription and store pushover_user_key into user preferences if valid token/otp';
|
||||||
|
|
||||||
-- Telegram OTP Validation
|
-- Telegram OTP Validation
|
||||||
-- Expose as an API endpoint
|
-- Expose as an API endpoint
|
||||||
@@ -359,7 +372,7 @@ $telegram$ language plpgsql security definer;
|
|||||||
-- Description
|
-- Description
|
||||||
COMMENT ON FUNCTION
|
COMMENT ON FUNCTION
|
||||||
api.telegram_fn
|
api.telegram_fn
|
||||||
IS 'Store telegram chat details into user preferences if valid token/otp';
|
IS 'Confirm telegram user and store telegram chat details into user preferences if valid token/otp';
|
||||||
|
|
||||||
-- Telegram user validation
|
-- Telegram user validation
|
||||||
DROP FUNCTION IF EXISTS auth.telegram_user_exists_fn;
|
DROP FUNCTION IF EXISTS auth.telegram_user_exists_fn;
|
||||||
@@ -410,7 +423,6 @@ AS $telegram_otp$
|
|||||||
END IF;
|
END IF;
|
||||||
END;
|
END;
|
||||||
$telegram_otp$ language plpgsql security definer;
|
$telegram_otp$ language plpgsql security definer;
|
||||||
|
|
||||||
-- Description
|
-- Description
|
||||||
COMMENT ON FUNCTION
|
COMMENT ON FUNCTION
|
||||||
auth.telegram_otp_fn
|
auth.telegram_otp_fn
|
||||||
|
@@ -91,24 +91,34 @@ GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA api TO user_role;
|
|||||||
-- TODO should not be need !! ??
|
-- TODO should not be need !! ??
|
||||||
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public 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 TO user_role;
|
||||||
|
GRANT SELECT ON TABLE api.log_view TO user_role;
|
||||||
|
GRANT SELECT ON TABLE api.stays_view TO user_role;
|
||||||
|
GRANT SELECT ON TABLE api.stay_view TO user_role;
|
||||||
|
GRANT SELECT ON TABLE api.moorages_view TO user_role;
|
||||||
|
GRANT SELECT ON TABLE api.monitoring_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;
|
||||||
-- Update ownership for security user_role as run by web user.
|
-- Update ownership for security user_role as run by web user.
|
||||||
-- Web listing
|
-- Web listing
|
||||||
ALTER VIEW api.stays_view OWNER TO user_role;
|
--ALTER VIEW api.stays_view OWNER TO user_role;
|
||||||
ALTER VIEW api.moorages_view OWNER TO user_role;
|
--ALTER VIEW api.moorages_view OWNER TO user_role;
|
||||||
ALTER VIEW api.logs_view OWNER TO user_role;
|
--ALTER VIEW api.logs_view OWNER TO user_role;
|
||||||
ALTER VIEW api.vessel_p_view OWNER TO user_role;
|
--ALTER VIEW api.vessel_p_view OWNER TO user_role;
|
||||||
ALTER VIEW api.monitoring_view OWNER TO user_role;
|
--ALTER VIEW api.monitoring_view OWNER TO user_role;
|
||||||
-- Remove all permissions except select
|
-- Remove all permissions except select
|
||||||
REVOKE UPDATE, TRUNCATE, REFERENCES, DELETE, TRIGGER, INSERT ON TABLE api.stays_view FROM user_role;
|
--REVOKE UPDATE, TRUNCATE, REFERENCES, DELETE, TRIGGER, INSERT ON TABLE api.stays_view FROM user_role;
|
||||||
REVOKE UPDATE, TRUNCATE, REFERENCES, DELETE, TRIGGER, INSERT ON TABLE api.moorages_view FROM user_role;
|
--REVOKE UPDATE, TRUNCATE, REFERENCES, DELETE, TRIGGER, INSERT ON TABLE api.moorages_view FROM user_role;
|
||||||
REVOKE UPDATE, TRUNCATE, REFERENCES, DELETE, TRIGGER, INSERT ON TABLE api.logs_view FROM user_role;
|
--REVOKE UPDATE, TRUNCATE, REFERENCES, DELETE, TRIGGER, INSERT ON TABLE api.logs_view FROM user_role;
|
||||||
REVOKE UPDATE, TRUNCATE, REFERENCES, DELETE, TRIGGER, INSERT ON TABLE api.monitoring_view FROM user_role;
|
--REVOKE UPDATE, TRUNCATE, REFERENCES, DELETE, TRIGGER, INSERT ON TABLE api.monitoring_view FROM user_role;
|
||||||
|
|
||||||
-- Allow read and update on VIEWS
|
-- Allow read and update on VIEWS
|
||||||
-- Web detail view
|
-- Web detail view
|
||||||
ALTER VIEW api.log_view OWNER TO user_role;
|
--ALTER VIEW api.log_view OWNER TO user_role;
|
||||||
-- Remove all permissions except select and update
|
-- Remove all permissions except select and update
|
||||||
REVOKE TRUNCATE, DELETE, TRIGGER, INSERT ON TABLE api.log_view FROM user_role;
|
--REVOKE TRUNCATE, DELETE, TRIGGER, INSERT ON TABLE api.log_view FROM user_role;
|
||||||
|
|
||||||
ALTER VIEW api.vessels_view OWNER TO user_role;
|
ALTER VIEW api.vessels_view OWNER TO user_role;
|
||||||
-- Remove all permissions except select and update
|
-- Remove all permissions except select and update
|
||||||
|
@@ -1 +1 @@
|
|||||||
0.0.9
|
0.0.10
|
||||||
|
Reference in New Issue
Block a user