mirror of
https://github.com/xbgmsharp/postgsail.git
synced 2025-09-17 11:17:46 +00:00
Compare commits
58 Commits
Author | SHA1 | Date | |
---|---|---|---|
![]() |
8c777cd028 | ||
![]() |
cfe3105f87 | ||
![]() |
5af24a1878 | ||
![]() |
0aae8d002b | ||
![]() |
22c69a2fd9 | ||
![]() |
c5f1b85a16 | ||
![]() |
0157fe12e5 | ||
![]() |
ead2b99e7f | ||
![]() |
711d5a0d40 | ||
![]() |
7e52065ef8 | ||
![]() |
f65873db81 | ||
![]() |
347299d76e | ||
![]() |
effeb29915 | ||
![]() |
9329a6d04b | ||
![]() |
70be4fb295 | ||
![]() |
5960447297 | ||
![]() |
f240222b98 | ||
![]() |
0218f2fa73 | ||
![]() |
79a96c7556 | ||
![]() |
21f96483f5 | ||
![]() |
4c6d6290f0 | ||
![]() |
dc02dc886d | ||
![]() |
6355f98792 | ||
![]() |
7543c93dcf | ||
![]() |
d76964f3db | ||
![]() |
de651ea7ab | ||
![]() |
fddd3df05e | ||
![]() |
472131efbd | ||
![]() |
1f7bb433e2 | ||
![]() |
c4fa9f5512 | ||
![]() |
b005f592e9 | ||
![]() |
6cc13313f1 | ||
![]() |
fdb466abde | ||
![]() |
5f0adb67c8 | ||
![]() |
2e170c5480 | ||
![]() |
5dd2875b91 | ||
![]() |
ee131e0e70 | ||
![]() |
6426e14d54 | ||
![]() |
8fff17dee3 | ||
![]() |
eb8ba54230 | ||
![]() |
f9ed13761c | ||
![]() |
e1e7da779e | ||
![]() |
c879c4bdab | ||
![]() |
e5f2469358 | ||
![]() |
480409de12 | ||
![]() |
9d8a7294e0 | ||
![]() |
e3ae6b4243 | ||
![]() |
268ce5b908 | ||
![]() |
ce55a58c87 | ||
![]() |
14e2103e0f | ||
![]() |
8025fc4d52 | ||
![]() |
117bdd2e3f | ||
![]() |
b37c33bccb | ||
![]() |
2507545d3f | ||
![]() |
b6ef06d382 | ||
![]() |
30de9b76af | ||
![]() |
8f1558f436 | ||
![]() |
636fae7ce6 |
@@ -8,15 +8,15 @@ module.exports = {
|
||||
},
|
||||
|
||||
rules: {
|
||||
//"name-casing": ["error", "snake"],
|
||||
"name-casing": ["error", "snake"],
|
||||
"prefer-jsonb-to-json": ["error"],
|
||||
"prefer-text-to-varchar": ["error"],
|
||||
//"prefer-timestamptz-to-timestamp": ["error"],
|
||||
//"prefer-identity-to-serial": ["error"],
|
||||
"prefer-timestamptz-to-timestamp": ["error"],
|
||||
"prefer-identity-to-serial": ["error"],
|
||||
//"name-inflection": ["error", "singular"],
|
||||
},
|
||||
|
||||
schemas: [{ name: "public" }, { name: "api" }],
|
||||
schemas: [{ name: "public" }, { name: "api" },{ name: "auth" }],
|
||||
|
||||
ignores: [],
|
||||
};
|
||||
};
|
||||
|
@@ -2,34 +2,33 @@
|
||||
The Entity-Relationship Diagram (ERD) provides a graphical representation of database tables, columns, and inter-relationships. ERD can give sufficient information for the database administrator to follow when developing and maintaining the database.
|
||||
|
||||
## A global overview
|
||||

|
||||
Auto generated Mermaid diagram using [mermerd](https://github.com/KarnerTh/mermerd) and [MermaidJs](https://github.com/mermaid-js/mermaid).
|
||||
|
||||
[PostgSail SQL Schema](https://github.com/xbgmsharp/postgsail/tree/main/ERD/postgsail.md "PostgSail SQL Schema")
|
||||
|
||||
## Further
|
||||
There is 3 main schemas:
|
||||
- API Schema ERD
|
||||
- tables
|
||||
- metrics
|
||||
- logbook
|
||||
- ...
|
||||
- functions
|
||||
- ...
|
||||

|
||||
- API Schema:
|
||||
- tables
|
||||
- metrics
|
||||
- logbook
|
||||
- ...
|
||||
- functions
|
||||
- ...
|
||||
|
||||
- Auth Schema ERD
|
||||
- Auth Schema:
|
||||
- tables
|
||||
- accounts
|
||||
- vessels
|
||||
- ...
|
||||
- functions
|
||||
- ...
|
||||

|
||||
|
||||
- Public Schema ERD
|
||||
- Public Schema:
|
||||
- tables
|
||||
- app_settings
|
||||
- tpl_messages
|
||||
- ...
|
||||
- functions
|
||||
- ...
|
||||

|
||||
|
||||
|
35
ERD/mermerdConfig.yaml
Normal file
35
ERD/mermerdConfig.yaml
Normal file
@@ -0,0 +1,35 @@
|
||||
# Connection properties
|
||||
connectionString: ${PGSAIL_DB_URI}
|
||||
|
||||
# Define what schemas should be used
|
||||
#useAllSchemas: true
|
||||
# or
|
||||
schema:
|
||||
- "public"
|
||||
- "api"
|
||||
- "auth"
|
||||
|
||||
# Define what tables should be used
|
||||
useAllTables: true
|
||||
# or
|
||||
#selectedTables:
|
||||
# - city
|
||||
# - customer
|
||||
|
||||
# Additional flags
|
||||
showAllConstraints: true
|
||||
encloseWithMermaidBackticks: true
|
||||
outputFileName: "postgsail.md"
|
||||
debug: true
|
||||
omitConstraintLabels: true
|
||||
omitAttributeKeys: true
|
||||
showDescriptions:
|
||||
- enumValues
|
||||
- columnComments
|
||||
- notNull
|
||||
showSchemaPrefix: true
|
||||
schemaPrefixSeparator: "_"
|
||||
|
||||
# Names must match the pattern <schema><schema_prefix><table>
|
||||
#relationshipLabels:
|
||||
# - "public_table public_another-table : label"
|
246
ERD/postgsail.md
Normal file
246
ERD/postgsail.md
Normal file
@@ -0,0 +1,246 @@
|
||||
```mermaid
|
||||
erDiagram
|
||||
api_logbook {
|
||||
text _from
|
||||
double_precision _from_lat
|
||||
double_precision _from_lng
|
||||
integer _from_moorage_id "Link api.moorages with api.logbook via FOREIGN KEY and REFERENCES"
|
||||
timestamp_with_time_zone _from_time "{NOT_NULL}"
|
||||
text _to
|
||||
double_precision _to_lat
|
||||
double_precision _to_lng
|
||||
integer _to_moorage_id "Link api.moorages with api.logbook via FOREIGN KEY and REFERENCES"
|
||||
timestamp_with_time_zone _to_time
|
||||
boolean active
|
||||
double_precision avg_speed
|
||||
numeric distance "in NM"
|
||||
interval duration "Best to use standard ISO 8601"
|
||||
jsonb extra "computed signalk metrics of interest, runTime, currentLevel, etc"
|
||||
integer id "{NOT_NULL}"
|
||||
double_precision max_speed
|
||||
double_precision max_wind_speed
|
||||
text name
|
||||
text notes
|
||||
geography track_geog "postgis geography type default SRID 4326 Unit: degres"
|
||||
jsonb track_geojson "store generated geojson with track metrics data using with LineString and Point features, we can not depend api.metrics table"
|
||||
geometry track_geom "postgis geometry type EPSG:4326 Unit: degres"
|
||||
text vessel_id "{NOT_NULL}"
|
||||
}
|
||||
|
||||
api_metadata {
|
||||
boolean active "trigger monitor online/offline"
|
||||
boolean active
|
||||
double_precision beam
|
||||
text client_id
|
||||
timestamp_with_time_zone created_at "{NOT_NULL}"
|
||||
double_precision height
|
||||
integer id "{NOT_NULL}"
|
||||
double_precision length
|
||||
numeric mmsi
|
||||
text name
|
||||
text plugin_version "{NOT_NULL}"
|
||||
numeric ship_type
|
||||
text signalk_version "{NOT_NULL}"
|
||||
timestamp_with_time_zone time "{NOT_NULL}"
|
||||
timestamp_with_time_zone updated_at "{NOT_NULL}"
|
||||
text vessel_id "Link auth.vessels with api.metadata via FOREIGN KEY and REFERENCES {NOT_NULL}"
|
||||
text vessel_id "{NOT_NULL}"
|
||||
}
|
||||
|
||||
api_metrics {
|
||||
double_precision anglespeedapparent
|
||||
text client_id
|
||||
double_precision courseovergroundtrue
|
||||
double_precision latitude "With CONSTRAINT but allow NULL value to be ignored silently by trigger"
|
||||
double_precision longitude "With CONSTRAINT but allow NULL value to be ignored silently by trigger"
|
||||
jsonb metrics
|
||||
double_precision speedoverground
|
||||
status status "<sailing,motoring,moored,anchored>"
|
||||
timestamp_with_time_zone time "{NOT_NULL}"
|
||||
text vessel_id "{NOT_NULL}"
|
||||
double_precision windspeedapparent
|
||||
}
|
||||
|
||||
api_moorages {
|
||||
text country
|
||||
geography geog "postgis geography type default SRID 4326 Unit: degres"
|
||||
boolean home_flag
|
||||
integer id "{NOT_NULL}"
|
||||
double_precision latitude
|
||||
double_precision longitude
|
||||
text name
|
||||
jsonb nominatim
|
||||
text notes
|
||||
jsonb overpass
|
||||
integer reference_count
|
||||
integer stay_code "Link api.stays_at with api.moorages via FOREIGN KEY and REFERENCES"
|
||||
interval stay_duration "Best to use standard ISO 8601"
|
||||
text vessel_id "{NOT_NULL}"
|
||||
}
|
||||
|
||||
api_stays {
|
||||
boolean active
|
||||
timestamp_with_time_zone arrived "{NOT_NULL}"
|
||||
timestamp_with_time_zone departed
|
||||
interval duration "Best to use standard ISO 8601"
|
||||
geography geog "postgis geography type default SRID 4326 Unit: degres"
|
||||
integer id "{NOT_NULL}"
|
||||
double_precision latitude
|
||||
double_precision longitude
|
||||
integer moorage_id "Link api.moorages with api.stays via FOREIGN KEY and REFERENCES"
|
||||
text name
|
||||
text notes
|
||||
integer stay_code "Link api.stays_at with api.stays via FOREIGN KEY and REFERENCES"
|
||||
text vessel_id "{NOT_NULL}"
|
||||
}
|
||||
|
||||
api_stays_at {
|
||||
text description "{NOT_NULL}"
|
||||
integer stay_code "{NOT_NULL}"
|
||||
}
|
||||
|
||||
auth_accounts {
|
||||
timestamp_with_time_zone connected_at "{NOT_NULL}"
|
||||
timestamp_with_time_zone created_at "{NOT_NULL}"
|
||||
citext email "{NOT_NULL}"
|
||||
text first "User first name with CONSTRAINT CHECK {NOT_NULL}"
|
||||
text last "User last name with CONSTRAINT CHECK {NOT_NULL}"
|
||||
text pass "{NOT_NULL}"
|
||||
jsonb preferences
|
||||
integer public_id "{NOT_NULL}"
|
||||
name role "{NOT_NULL}"
|
||||
timestamp_with_time_zone updated_at "{NOT_NULL}"
|
||||
text user_id "{NOT_NULL}"
|
||||
}
|
||||
|
||||
auth_otp {
|
||||
text otp_pass "{NOT_NULL}"
|
||||
timestamp_with_time_zone otp_timestamp
|
||||
smallint otp_tries "{NOT_NULL}"
|
||||
citext user_email "{NOT_NULL}"
|
||||
}
|
||||
|
||||
auth_vessels {
|
||||
timestamp_with_time_zone created_at "{NOT_NULL}"
|
||||
numeric mmsi
|
||||
text name "{NOT_NULL}"
|
||||
citext owner_email "{NOT_NULL}"
|
||||
name role "{NOT_NULL}"
|
||||
timestamp_with_time_zone updated_at "{NOT_NULL}"
|
||||
text vessel_id "{NOT_NULL}"
|
||||
}
|
||||
|
||||
public_aistypes {
|
||||
text description
|
||||
numeric id
|
||||
}
|
||||
|
||||
public_app_settings {
|
||||
text name "application settings name key {NOT_NULL}"
|
||||
text value "application settings value {NOT_NULL}"
|
||||
}
|
||||
|
||||
public_badges {
|
||||
text description
|
||||
text name
|
||||
}
|
||||
|
||||
public_email_templates {
|
||||
text email_content
|
||||
text email_subject
|
||||
text name
|
||||
text pushover_message
|
||||
text pushover_title
|
||||
}
|
||||
|
||||
public_geocoders {
|
||||
text name
|
||||
text reverse_url
|
||||
text url
|
||||
}
|
||||
|
||||
public_iso3166 {
|
||||
text alpha_2
|
||||
text alpha_3
|
||||
text country
|
||||
integer id
|
||||
}
|
||||
|
||||
public_mid {
|
||||
text country
|
||||
integer country_id
|
||||
numeric id
|
||||
}
|
||||
|
||||
public_ne_10m_geography_marine_polys {
|
||||
text changed
|
||||
text featurecla
|
||||
geometry geom
|
||||
integer gid "{NOT_NULL}"
|
||||
text label
|
||||
double_precision max_label
|
||||
double_precision min_label
|
||||
text name
|
||||
text name_ar
|
||||
text name_bn
|
||||
text name_de
|
||||
text name_el
|
||||
text name_en
|
||||
text name_es
|
||||
text name_fa
|
||||
text name_fr
|
||||
text name_he
|
||||
text name_hi
|
||||
text name_hu
|
||||
text name_id
|
||||
text name_it
|
||||
text name_ja
|
||||
text name_ko
|
||||
text name_nl
|
||||
text name_pl
|
||||
text name_pt
|
||||
text name_ru
|
||||
text name_sv
|
||||
text name_tr
|
||||
text name_uk
|
||||
text name_ur
|
||||
text name_vi
|
||||
text name_zh
|
||||
text name_zht
|
||||
text namealt
|
||||
bigint ne_id
|
||||
text note
|
||||
smallint scalerank
|
||||
text wikidataid
|
||||
}
|
||||
|
||||
public_process_queue {
|
||||
text channel "{NOT_NULL}"
|
||||
integer id "{NOT_NULL}"
|
||||
text payload "{NOT_NULL}"
|
||||
timestamp_with_time_zone processed
|
||||
text ref_id "either user_id or vessel_id {NOT_NULL}"
|
||||
timestamp_with_time_zone stored "{NOT_NULL}"
|
||||
}
|
||||
|
||||
public_spatial_ref_sys {
|
||||
character_varying auth_name
|
||||
integer auth_srid
|
||||
character_varying proj4text
|
||||
integer srid "{NOT_NULL}"
|
||||
character_varying srtext
|
||||
}
|
||||
|
||||
api_logbook }o--|| api_metadata : ""
|
||||
api_logbook }o--|| api_moorages : ""
|
||||
api_logbook }o--|| api_moorages : ""
|
||||
api_metadata }o--|| auth_vessels : ""
|
||||
api_metrics }o--|| api_metadata : ""
|
||||
api_moorages }o--|| api_metadata : ""
|
||||
api_stays }o--|| api_metadata : ""
|
||||
api_moorages }o--|| api_stays_at : ""
|
||||
api_stays }o--|| api_moorages : ""
|
||||
api_stays }o--|| api_stays_at : ""
|
||||
auth_otp |o--|| auth_accounts : ""
|
||||
auth_vessels |o--|| auth_accounts : ""
|
||||
```
|
@@ -3,7 +3,7 @@
|
||||
Effortless cloud based solution for storing and sharing your SignalK data. Allow you to effortlessly log your sails and monitor your boat with historical data.
|
||||
|
||||
[](https://github.com/xbgmsharp/postgsail/releases/latest)
|
||||
[](#license)
|
||||
[](#license)
|
||||
[](https://github.com/xbgmsharp/postgsail/issues)
|
||||
|
||||
[](https://github.com/xbgmsharp/postgsail/actions/workflows/db-test.yml)
|
||||
@@ -25,7 +25,7 @@ postgsail-telegram-bot:
|
||||
- Automatically capture the details of your voyages (boat speed, heading, wind speed, etc).
|
||||
- Timelapse video your trips, with or without time control.
|
||||
- Add custom notes to your logs.
|
||||
- Export to CSV or GPX or KLM and download your logs.
|
||||
- Export to CSV, GPX, GeoJSON, KML and download your logs.
|
||||
- Aggregate your trip statistics: Longest voyage, time spent at anchorages, home ports etc.
|
||||
- See your moorages on a global map, with incoming and outgoing voyages from each trip.
|
||||
- Monitor your boat (position, depth, wind, temperature, battery charge status, etc.) remotely.
|
||||
@@ -144,7 +144,7 @@ Next, to ingest data from signalk, you need to install [signalk-postgsail](https
|
||||
Also, if you like, you can import saillogger data using the postgsail helpers, [postgsail-helpers](https://github.com/xbgmsharp/postgsail-helpers).
|
||||
|
||||
You might want to import your influxdb1 data as well, [outflux](https://github.com/timescale/outflux).
|
||||
Any taker on influxdb2 to PostgSail? It is definitely possible.
|
||||
For InfluxDB 2.x and 3.x. You will need to enable the 1.x APIs to use them. Consult the InfluxDB documentation for more details.
|
||||
|
||||
Last, if you like, you can import the sample data from Signalk NMEA Plaka by running the tests.
|
||||
If everything goes well all tests pass successfully and you should receive a few notifications by email or PushOver or Telegram.
|
||||
@@ -222,4 +222,4 @@ Feel free to contribute.
|
||||
|
||||
### License
|
||||
|
||||
This script is free software, Apache License Version 2.0.
|
||||
This is a free software, Apache License Version 2.0.
|
||||
|
@@ -45,6 +45,7 @@ services:
|
||||
PGRST_DB_ANON_ROLE: api_anonymous
|
||||
PGRST_OPENAPI_SERVER_PROXY_URI: http://127.0.0.1:3000
|
||||
PGRST_DB_PRE_REQUEST: public.check_jwt
|
||||
PGRST_DB_POOL: 20
|
||||
PGRST_DB_URI: ${PGRST_DB_URI}
|
||||
PGRST_JWT_SECRET: ${PGRST_JWT_SECRET}
|
||||
depends_on:
|
||||
|
2
frontend
2
frontend
Submodule frontend updated: 086b393568...061c4cb6bf
@@ -5,18 +5,18 @@
|
||||
-- https://groups.google.com/g/signalk/c/W2H15ODCic4
|
||||
--
|
||||
-- Description:
|
||||
-- Insert data into table metadata from API using PostgREST
|
||||
-- Insert data into table metrics from API using PostgREST
|
||||
-- TimescaleDB Hypertable to store signalk metrics
|
||||
-- pgsql functions to generate logbook, stays, moorages
|
||||
-- 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 and/or pushover
|
||||
-- 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)-> metadata_upsert_trigger_fn (INSERT or UPDATE)
|
||||
-- vessels signalk -(POST)-> metrics -> metrics -(trigger)-> metrics_fn new log,stay,moorage
|
||||
-- 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)
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
|
||||
|
@@ -8,7 +8,7 @@
|
||||
---------------------------------------------------------------------------
|
||||
-- Metadata from signalk
|
||||
CREATE TABLE IF NOT EXISTS api.metadata(
|
||||
id SERIAL PRIMARY KEY,
|
||||
id INT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
name TEXT NULL,
|
||||
mmsi NUMERIC NULL,
|
||||
client_id TEXT NULL,
|
||||
@@ -20,10 +20,10 @@ CREATE TABLE IF NOT EXISTS api.metadata(
|
||||
ship_type NUMERIC NULL,
|
||||
plugin_version TEXT NOT NULL,
|
||||
signalk_version TEXT NOT NULL,
|
||||
time TIMESTAMP WITHOUT TIME ZONE NOT NULL, -- should be rename to last_update !?
|
||||
time TIMESTAMPTZ NOT NULL, -- should be rename to last_update !?
|
||||
active BOOLEAN DEFAULT True, -- trigger monitor online/offline
|
||||
created_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW()
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
);
|
||||
-- Description
|
||||
COMMENT ON TABLE
|
||||
@@ -42,7 +42,7 @@ CREATE INDEX metadata_name_idx ON api.metadata (name);
|
||||
CREATE TYPE status AS ENUM ('sailing', 'motoring', 'moored', 'anchored');
|
||||
-- Table api.metrics
|
||||
CREATE TABLE IF NOT EXISTS api.metrics (
|
||||
time TIMESTAMP WITHOUT TIME ZONE NOT NULL,
|
||||
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,
|
||||
@@ -95,13 +95,15 @@ SELECT create_hypertable('api.metrics', 'time', chunk_time_interval => INTERVAL
|
||||
-- Check unused index
|
||||
|
||||
CREATE TABLE IF NOT EXISTS api.logbook(
|
||||
id SERIAL PRIMARY KEY,
|
||||
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,
|
||||
@@ -109,8 +111,8 @@ CREATE TABLE IF NOT EXISTS api.logbook(
|
||||
track_geom geometry(LINESTRING,4326) NULL,
|
||||
track_geog geography(LINESTRING) NULL,
|
||||
track_geojson JSONB NULL,
|
||||
_from_time TIMESTAMP WITHOUT TIME ZONE NOT NULL,
|
||||
_to_time TIMESTAMP WITHOUT TIME ZONE 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,
|
||||
@@ -125,9 +127,12 @@ COMMENT ON TABLE
|
||||
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_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 );
|
||||
@@ -139,15 +144,16 @@ COMMENT ON COLUMN api.logbook.track_geojson IS 'store generated geojson with tra
|
||||
-- Stays
|
||||
-- virtual logbook by boat?
|
||||
CREATE TABLE IF NOT EXISTS api.stays(
|
||||
id SERIAL PRIMARY KEY,
|
||||
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 TIMESTAMP WITHOUT TIME ZONE NOT NULL,
|
||||
departed TIMESTAMP WITHOUT TIME ZONE,
|
||||
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
|
||||
@@ -159,21 +165,20 @@ COMMENT ON TABLE
|
||||
|
||||
-- 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.
|
||||
COMMENT ON COLUMN api.stays.duration IS 'Best to use standard ISO 8601';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Moorages
|
||||
-- virtual logbook by boat?
|
||||
CREATE TABLE IF NOT EXISTS api.moorages(
|
||||
id SERIAL PRIMARY KEY,
|
||||
--client_id VARCHAR(255) NOT NULL REFERENCES api.metadata(client_id) ON DELETE RESTRICT,
|
||||
--client_id VARCHAR(255) NULL,
|
||||
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_id INT NOT NULL, -- needed?
|
||||
stay_code INT DEFAULT 1, -- needed? REFERENCES api.stays_at(stay_code)
|
||||
stay_duration INTERVAL NULL,
|
||||
reference_count INT DEFAULT 1,
|
||||
@@ -181,7 +186,9 @@ CREATE TABLE IF NOT EXISTS api.moorages(
|
||||
longitude DOUBLE PRECISION NULL,
|
||||
geog GEOGRAPHY(POINT) NULL,
|
||||
home_flag BOOLEAN DEFAULT false,
|
||||
notes TEXT NULL
|
||||
notes TEXT NULL,
|
||||
overpass JSONB NULL,
|
||||
nominatim JSONB NULL
|
||||
);
|
||||
-- Description
|
||||
COMMENT ON TABLE
|
||||
@@ -193,11 +200,12 @@ 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 NOT NULL,
|
||||
stay_code INTEGER UNIQUE NOT NULL,
|
||||
description TEXT NOT NULL
|
||||
);
|
||||
-- Description
|
||||
@@ -248,7 +256,8 @@ CREATE FUNCTION metadata_upsert_trigger_fn() RETURNS trigger AS $metadata_upsert
|
||||
ship_type = NEW.ship_type,
|
||||
plugin_version = NEW.plugin_version,
|
||||
signalk_version = NEW.signalk_version,
|
||||
time = NEW.time,
|
||||
-- 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
|
||||
@@ -257,7 +266,9 @@ CREATE FUNCTION metadata_upsert_trigger_fn() RETURNS trigger AS $metadata_upsert
|
||||
-- set vessel_id from jwt if not present in INSERT query
|
||||
NEW.vessel_id := current_setting('vessel.id');
|
||||
END IF;
|
||||
-- Insert new vessel metadata and
|
||||
-- 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;
|
||||
@@ -320,13 +331,13 @@ COMMENT ON TRIGGER
|
||||
DROP FUNCTION IF EXISTS metrics_trigger_fn;
|
||||
CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
|
||||
DECLARE
|
||||
previous_status varchar;
|
||||
previous_time TIMESTAMP WITHOUT TIME ZONE;
|
||||
stay_code integer;
|
||||
logbook_id integer;
|
||||
stay_id integer;
|
||||
valid_status BOOLEAN;
|
||||
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;
|
||||
@@ -337,20 +348,20 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
|
||||
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 coalesce(m.status, 'moored'), m.time INTO previous_status, previous_time
|
||||
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_status;
|
||||
IF previous_time = NEW.time THEN
|
||||
--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_time, NEW.time;
|
||||
RAISE WARNING 'Metrics Ignoring metric, vessel_id [%], duplicate time [%] = [%]', NEW.vessel_id, previous_metric.time, NEW.time;
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
IF previous_time > NEW.time THEN
|
||||
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_time [%] > [%]', NEW.vessel_id, previous_time, NEW.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
|
||||
@@ -383,18 +394,30 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
|
||||
RAISE WARNING 'Metrics Ignoring metric, vessel_id [%], latitude and longitude are equal [%] [%]', NEW.vessel_id, NEW.latitude, NEW.longitude;
|
||||
RETURN NULL;
|
||||
END IF;
|
||||
-- Check if status is null
|
||||
IF NEW.status IS NULL THEN
|
||||
-- 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_status IS NULL THEN
|
||||
IF previous_metric.status IS NULL THEN
|
||||
IF NEW.status = 'anchored' THEN
|
||||
RAISE WARNING 'Metrics Unknown previous_status from vessel_id [%], [%] set to default current status [%]', NEW.vessel_id, previous_status, NEW.status;
|
||||
previous_status := NEW.status;
|
||||
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_status from vessel_id [%], [%] set to default status moored vs [%]', NEW.vessel_id, previous_status, NEW.status;
|
||||
previous_status := 'moored';
|
||||
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
|
||||
@@ -404,7 +427,7 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
|
||||
-- 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;
|
||||
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)::name[]) INTO valid_status;
|
||||
@@ -422,10 +445,10 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
|
||||
|
||||
-- Check the state and if any previous/current entry
|
||||
-- If change of state and new status is sailing or motoring
|
||||
IF previous_status::TEXT <> NEW.status::TEXT AND
|
||||
( (NEW.status::TEXT = 'sailing' AND previous_status::TEXT <> 'motoring')
|
||||
OR (NEW.status::TEXT = 'motoring' AND previous_status::TEXT <> 'sailing') ) THEN
|
||||
RAISE WARNING 'Metrics Update status, try new logbook, New:[%] Previous:[%]', NEW.status, previous_status;
|
||||
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
|
||||
@@ -433,7 +456,7 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
|
||||
(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;
|
||||
RAISE WARNING 'Metrics Insert new logbook, logbook_id [%] [%] [%]', logbook_id, NEW.status, NEW.time;
|
||||
ELSE
|
||||
UPDATE api.logbook
|
||||
SET
|
||||
@@ -442,7 +465,7 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
|
||||
_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;
|
||||
RAISE WARNING 'Metrics Existing logbook logbook_id [%] [%] [%]', logbook_id, NEW.status, NEW.time;
|
||||
END IF;
|
||||
|
||||
-- End current stay
|
||||
@@ -453,20 +476,20 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
|
||||
active = false,
|
||||
departed = NEW.time
|
||||
WHERE id = stay_id;
|
||||
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 stay entry to process queue for further processing
|
||||
INSERT INTO process_queue (channel, payload, stored, ref_id)
|
||||
VALUES ('new_moorage', stay_id, now(), current_setting('vessel.id', true));
|
||||
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_status::TEXT <> NEW.status::TEXT AND
|
||||
( (NEW.status::TEXT = 'moored' AND previous_status::TEXT <> 'anchored')
|
||||
OR (NEW.status::TEXT = 'anchored' AND previous_status::TEXT <> 'moored') ) THEN
|
||||
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_status;
|
||||
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;
|
||||
@@ -480,15 +503,14 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
|
||||
(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;
|
||||
-- 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 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
|
||||
departed = NEW.time,
|
||||
notes = 'Invalid stay?'
|
||||
WHERE id = stay_id;
|
||||
END IF;
|
||||
|
||||
@@ -507,9 +529,9 @@ CREATE FUNCTION metrics_trigger_fn() RETURNS trigger AS $metrics$
|
||||
WHERE id = logbook_id;
|
||||
-- Add logbook entry to process queue for later processing
|
||||
INSERT INTO process_queue (channel, payload, stored, ref_id)
|
||||
VALUEs ('new_logbook', logbook_id, now(), current_setting('vessel.id', true));
|
||||
VALUES ('new_logbook', logbook_id, now(), current_setting('vessel.id', true));
|
||||
ELSE
|
||||
RAISE WARNING 'Metrics Invalid logbook_id [%] [%]', logbook_id, NEW.time;
|
||||
RAISE WARNING 'Metrics Invalid logbook_id [%] [%] [%]', logbook_id, NEW.status, NEW.time;
|
||||
END IF;
|
||||
END IF;
|
||||
RETURN NEW; -- Finally insert the actual new metric
|
||||
@@ -528,3 +550,57 @@ CREATE TRIGGER metrics_trigger BEFORE INSERT ON api.metrics
|
||||
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 update of name and stay_code on logbook and stays reference';
|
||||
|
@@ -41,8 +41,8 @@ CREATE OR REPLACE FUNCTION api.timelapse_fn(
|
||||
WITH logbook as (
|
||||
SELECT track_geom
|
||||
FROM api.logbook
|
||||
WHERE _from_time >= start_log::TIMESTAMP WITHOUT TIME ZONE
|
||||
AND _to_time <= end_date::TIMESTAMP WITHOUT TIME ZONE + interval '23 hours 59 minutes'
|
||||
WHERE _from_time >= start_log::TIMESTAMPTZ
|
||||
AND _to_time <= end_date::TIMESTAMPTZ + interval '23 hours 59 minutes'
|
||||
AND track_geom IS NOT NULL
|
||||
ORDER BY _from_time ASC
|
||||
)
|
||||
@@ -112,7 +112,7 @@ COMMENT ON FUNCTION
|
||||
--
|
||||
DROP FUNCTION IF EXISTS api.export_logbook_gpx_fn;
|
||||
CREATE OR REPLACE FUNCTION api.export_logbook_gpx_fn(IN _id INTEGER) RETURNS pg_catalog.xml
|
||||
AS $export_logbook_gpx2$
|
||||
AS $export_logbook_gpx$
|
||||
DECLARE
|
||||
app_settings jsonb;
|
||||
BEGIN
|
||||
@@ -159,7 +159,7 @@ AS $export_logbook_gpx2$
|
||||
AND l.id = _id
|
||||
GROUP BY l.name,l.notes,l.id;
|
||||
END;
|
||||
$export_logbook_gpx2$ LANGUAGE plpgsql;
|
||||
$export_logbook_gpx$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.export_logbook_gpx_fn
|
||||
@@ -554,14 +554,17 @@ COMMENT ON FUNCTION
|
||||
DROP FUNCTION IF EXISTS api.export_moorages_gpx_fn;
|
||||
CREATE FUNCTION api.export_moorages_gpx_fn() RETURNS pg_catalog.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",
|
||||
'https://iot.openplotter.cloud' as "xmlns:postgsail",
|
||||
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"),
|
||||
@@ -573,14 +576,14 @@ CREATE FUNCTION api.export_moorages_gpx_fn() RETURNS pg_catalog.xml AS $export_m
|
||||
concat('Last Stayed On: ', 'TODO last seen',
|
||||
E'\nTotal Stays: ', m.stay_duration,
|
||||
E'\nTotal Arrivals and Departures: ', m.reference_count,
|
||||
E'\nLink: ', concat('https://iot.openplotter.cloud/moorage/', m.id)),
|
||||
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('https://iot.openplotter.cloud/moorage/', m.id) as href),
|
||||
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", 1),
|
||||
xmlelement(name "postgsail:link", concat('https://iot.openplotter.cloud/moorage/', 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)
|
||||
@@ -603,13 +606,13 @@ CREATE OR REPLACE FUNCTION api.stats_logs_fn(
|
||||
IN end_date TEXT DEFAULT NULL,
|
||||
OUT stats JSON) RETURNS JSON AS $stats_logs$
|
||||
DECLARE
|
||||
_start_date TIMESTAMP WITHOUT TIME ZONE DEFAULT '1970-01-01';
|
||||
_end_date TIMESTAMP WITHOUT TIME ZONE DEFAULT NOW();
|
||||
_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::TIMESTAMP WITHOUT TIME ZONE;
|
||||
_end_date := end_date::TIMESTAMP WITHOUT TIME ZONE;
|
||||
_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
|
||||
@@ -618,8 +621,8 @@ CREATE OR REPLACE FUNCTION api.stats_logs_fn(
|
||||
logs_view AS (
|
||||
SELECT *
|
||||
FROM api.logbook l
|
||||
WHERE _from_time >= _start_date::TIMESTAMP WITHOUT TIME ZONE
|
||||
AND _to_time <= _end_date::TIMESTAMP WITHOUT TIME ZONE + interval '23 hours 59 minutes'
|
||||
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
|
||||
@@ -671,21 +674,21 @@ CREATE OR REPLACE FUNCTION api.stats_stays_fn(
|
||||
IN end_date TEXT DEFAULT NULL,
|
||||
OUT stats JSON) RETURNS JSON AS $stats_stays$
|
||||
DECLARE
|
||||
_start_date TIMESTAMP WITHOUT TIME ZONE DEFAULT '1970-01-01';
|
||||
_end_date TIMESTAMP WITHOUT TIME ZONE DEFAULT NOW();
|
||||
_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::TIMESTAMP WITHOUT TIME ZONE;
|
||||
_end_date := end_date::TIMESTAMP WITHOUT TIME ZONE;
|
||||
_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::TIMESTAMP WITHOUT TIME ZONE
|
||||
AND departed <= _end_date::TIMESTAMP WITHOUT TIME ZONE + interval '23 hours 59 minutes'
|
||||
WHERE arrived >= _start_date::TIMESTAMPTZ
|
||||
AND departed <= _end_date::TIMESTAMPTZ + interval '23 hours 59 minutes'
|
||||
AND s.id = m.stay_id
|
||||
),
|
||||
home_ports AS (
|
||||
@@ -737,6 +740,9 @@ CREATE OR REPLACE FUNCTION api.delete_logbook_fn(IN _id integer) RETURNS BOOLEAN
|
||||
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'
|
||||
@@ -754,14 +760,14 @@ CREATE OR REPLACE FUNCTION api.delete_logbook_fn(IN _id integer) RETURNS BOOLEAN
|
||||
AND s.arrived = logbook_rec._to_time;
|
||||
-- Find previous stays
|
||||
SELECT id INTO previous_stays_id
|
||||
FROM api.stays s
|
||||
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::timestamp without time zone,
|
||||
SET departed = current_stays_departed::TIMESTAMPTZ,
|
||||
active = current_stays_active
|
||||
WHERE vessel_id = current_setting('vessel.id', false)
|
||||
AND id = previous_stays_id;
|
||||
|
@@ -48,9 +48,11 @@ CREATE OR REPLACE VIEW api.logs_view WITH (security_invoker=true,security_barrie
|
||||
_to as "to",
|
||||
_to_time as "ended",
|
||||
distance as "distance",
|
||||
duration as "duration"
|
||||
duration as "duration",
|
||||
_from_moorage_id,_to_moorage_id
|
||||
FROM api.logbook l
|
||||
WHERE _to_time IS NOT NULL
|
||||
WHERE name IS NOT NULL
|
||||
AND _to_time IS NOT NULL
|
||||
ORDER BY _from_time DESC;
|
||||
-- Description
|
||||
COMMENT ON VIEW
|
||||
@@ -66,9 +68,11 @@ CREATE MATERIALIZED VIEW api.logs_mat_view AS
|
||||
_to as "to",
|
||||
_to_time as "ended",
|
||||
distance as "distance",
|
||||
duration as "duration"
|
||||
duration as "duration",
|
||||
_from_moorage_id,_to_moorage_id
|
||||
FROM api.logbook l
|
||||
WHERE _to_time IS NOT NULL
|
||||
WHERE name IS NOT NULL
|
||||
AND _to_time IS NOT NULL
|
||||
ORDER BY _from_time DESC;
|
||||
-- Description
|
||||
COMMENT ON MATERIALIZED VIEW
|
||||
@@ -90,7 +94,9 @@ CREATE OR REPLACE VIEW api.log_view WITH (security_invoker=true,security_barrier
|
||||
avg_speed as avg_speed,
|
||||
max_speed as max_speed,
|
||||
max_wind_speed as max_wind_speed,
|
||||
extra as extra
|
||||
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;
|
||||
@@ -104,30 +110,28 @@ COMMENT ON 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,
|
||||
concat(
|
||||
extract(DAYS FROM (s.departed-s.arrived)::interval),
|
||||
' days',
|
||||
--DATE_TRUNC('day', s.departed-s.arrived),
|
||||
' stay at ',
|
||||
s.name,
|
||||
' in ',
|
||||
RTRIM(TO_CHAR(s.departed, 'Month')),
|
||||
' ',
|
||||
TO_CHAR(s.departed, 'YYYY')
|
||||
) as "name",
|
||||
s.name AS "moorage",
|
||||
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 s, api.stays_at sa, api.moorages m
|
||||
WHERE departed IS NOT NULL
|
||||
LEFT JOIN api.logbook As _from ON _from._from_moorage_id = m.id
|
||||
LEFT JOIN api.logbook AS _to ON _to._to_moorage_id = m.id
|
||||
WHERE s.departed IS NOT NULL
|
||||
AND s.name IS NOT NULL
|
||||
AND s.stay_code = sa.stay_code
|
||||
AND s.id = m.stay_id
|
||||
AND s.moorage_id = m.id
|
||||
ORDER BY s.arrived DESC;
|
||||
-- Description
|
||||
COMMENT ON VIEW
|
||||
@@ -137,30 +141,28 @@ COMMENT ON 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,
|
||||
concat(
|
||||
extract(DAYS FROM (s.departed-s.arrived)::interval),
|
||||
' days',
|
||||
--DATE_TRUNC('day', s.departed-s.arrived),
|
||||
' stay at ',
|
||||
s.name,
|
||||
' in ',
|
||||
RTRIM(TO_CHAR(s.departed, 'Month')),
|
||||
' ',
|
||||
TO_CHAR(s.departed, 'YYYY')
|
||||
) as "name",
|
||||
s.name AS "moorage",
|
||||
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 s, api.stays_at sa, api.moorages m
|
||||
WHERE departed IS NOT NULL
|
||||
LEFT JOIN api.logbook As _from ON _from._from_moorage_id = m.id
|
||||
LEFT JOIN api.logbook AS _to ON _to._to_moorage_id = m.id
|
||||
WHERE s.departed IS NOT NULL
|
||||
AND s.name IS NOT NULL
|
||||
AND s.stay_code = sa.stay_code
|
||||
AND s.id = m.stay_id
|
||||
AND s.moorage_id = m.id
|
||||
ORDER BY s.arrived DESC;
|
||||
-- Description
|
||||
COMMENT ON VIEW
|
||||
@@ -191,17 +193,20 @@ CREATE OR REPLACE VIEW api.moorages_view WITH (security_invoker=true,security_ba
|
||||
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
|
||||
WHERE m.name IS NOT NULL
|
||||
AND geog IS NOT NULL
|
||||
-- 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.reference_count DESC;
|
||||
ORDER BY m.stay_duration DESC;
|
||||
-- Description
|
||||
COMMENT ON VIEW
|
||||
api.moorages_view
|
||||
@@ -215,11 +220,13 @@ CREATE OR REPLACE VIEW api.moorage_view WITH (security_invoker=true,security_bar
|
||||
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
|
||||
WHERE m.name IS NOT NULL
|
||||
-- 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
|
||||
@@ -227,6 +234,21 @@ 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 -- TODO
|
||||
SELECT
|
||||
_to.id AS _to_id,_to._to_time,
|
||||
_from.id AS _from_id,_from._from_time,
|
||||
m.stay_code,m.stay_duration,m.id
|
||||
FROM api.moorages m
|
||||
LEFT JOIN api.logbook As _from ON _from._from_moorage_id = m.id
|
||||
LEFT JOIN api.logbook AS _to ON _to._to_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
|
||||
@@ -269,7 +291,7 @@ CREATE OR REPLACE VIEW api.stats_logs_view WITH (security_invoker=true,security_
|
||||
concat( max(l.distance), ' NM, ', max(l.duration), ' hours') AS "longest_nonstop_sail"
|
||||
FROM api.logbook l)
|
||||
SELECT
|
||||
m.name as Name,
|
||||
m.name AS name,
|
||||
fm.time AS first,
|
||||
lm.time AS last,
|
||||
l.*
|
||||
|
@@ -150,12 +150,12 @@ INSERT INTO public.email_templates VALUES
|
||||
|
||||
-- table way
|
||||
CREATE TABLE IF NOT EXISTS public.process_queue (
|
||||
id SERIAL PRIMARY KEY,
|
||||
id INT PRIMARY KEY GENERATED ALWAYS AS IDENTITY,
|
||||
channel TEXT NOT NULL,
|
||||
payload TEXT NOT NULL,
|
||||
ref_id TEXT NOT NULL,
|
||||
stored TIMESTAMP WITHOUT TIME ZONE NOT NULL,
|
||||
processed TIMESTAMP WITHOUT TIME ZONE DEFAULT NULL
|
||||
stored TIMESTAMPTZ NOT NULL,
|
||||
processed TIMESTAMPTZ DEFAULT NULL
|
||||
);
|
||||
-- Description
|
||||
COMMENT ON TABLE
|
||||
@@ -190,6 +190,14 @@ begin
|
||||
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}', NEW.name);
|
||||
return NEW;
|
||||
END;
|
||||
$new_vessel_public$ language plpgsql;
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Tables Application Settings
|
||||
-- https://dba.stackexchange.com/questions/27296/storing-application-settings-with-different-datatypes#27297
|
||||
|
@@ -27,8 +27,8 @@ CREATE OR REPLACE FUNCTION public.logbook_metrics_dwithin_fn(
|
||||
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 m.time >= _start::TIMESTAMPTZ
|
||||
AND m.time <= _end::TIMESTAMPTZ
|
||||
AND vessel_id = current_setting('vessel.id', false)
|
||||
AND ST_DWithin(
|
||||
Geography(ST_MakePoint(m.longitude, m.latitude)),
|
||||
@@ -60,8 +60,8 @@ CREATE OR REPLACE FUNCTION public.logbook_update_avg_fn(
|
||||
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 m.time >= _start::TIMESTAMPTZ
|
||||
AND m.time <= _end::TIMESTAMPTZ
|
||||
AND vessel_id = current_setting('vessel.id', false);
|
||||
RAISE NOTICE '-> logbook_update_avg_fn avg for logbook id=%, avg_speed:%, max_speed:%, max_wind_speed:%, count:%', _id, avg_speed, max_speed, max_wind_speed, count_metric;
|
||||
END;
|
||||
@@ -87,8 +87,8 @@ CREATE FUNCTION public.logbook_update_geom_distance_fn(IN _id integer, IN _start
|
||||
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 m.time >= _start::TIMESTAMPTZ
|
||||
AND m.time <= _end::TIMESTAMPTZ
|
||||
AND vessel_id = current_setting('vessel.id', false)
|
||||
ORDER BY m.time ASC
|
||||
)
|
||||
@@ -129,6 +129,9 @@ CREATE FUNCTION public.logbook_update_geojson_fn(IN _id integer, IN _start text,
|
||||
max_speed,
|
||||
max_wind_speed,
|
||||
_from_time,
|
||||
_to_time
|
||||
_from_moorage_id,
|
||||
_to_moorage_id,
|
||||
notes,
|
||||
track_geom
|
||||
FROM api.logbook
|
||||
@@ -148,8 +151,8 @@ CREATE FUNCTION public.logbook_update_geojson_fn(IN _id integer, IN _start text,
|
||||
FROM api.metrics m
|
||||
WHERE m.latitude IS NOT NULL
|
||||
AND m.longitude IS NOT NULL
|
||||
AND time >= _start::TIMESTAMP WITHOUT TIME ZONE
|
||||
AND time <= _end::TIMESTAMP WITHOUT TIME ZONE
|
||||
AND time >= _start::TIMESTAMPTZ
|
||||
AND time <= _end::TIMESTAMPTZ
|
||||
AND vessel_id = current_setting('vessel.id', false)
|
||||
ORDER BY m.time ASC
|
||||
)
|
||||
@@ -228,8 +231,8 @@ AS $logbook_update_gpx$
|
||||
FROM api.metrics m
|
||||
WHERE m.latitude 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._to_time::TIMESTAMP WITHOUT TIME ZONE
|
||||
AND m.time >= log_rec._from_time::TIMESTAMPTZ
|
||||
AND m.time <= log_rec._to_time::TIMESTAMPTZ
|
||||
AND vessel_id = log_rec.vessel_id
|
||||
GROUP BY m.time
|
||||
ORDER BY m.time ASC;
|
||||
@@ -253,7 +256,7 @@ AS $logbook_get_extra_json$
|
||||
FROM api.metrics m,
|
||||
jsonb_each_text(m.metrics)
|
||||
WHERE key ILIKE search
|
||||
AND time = _start::timestamp without time zone
|
||||
AND time = _start::TIMESTAMPTZ
|
||||
AND vessel_id = current_setting('vessel.id', false)
|
||||
LOOP
|
||||
-- Engine Hours in seconds
|
||||
@@ -265,7 +268,7 @@ AS $logbook_get_extra_json$
|
||||
FROM api.metrics m,
|
||||
jsonb_each_text(m.metrics)
|
||||
WHERE key ILIKE metric_rec.key
|
||||
AND time = _end::timestamp without time zone
|
||||
AND time = _end::TIMESTAMPTZ
|
||||
AND vessel_id = current_setting('vessel.id', false)
|
||||
),
|
||||
metric AS (
|
||||
@@ -301,7 +304,7 @@ CREATE FUNCTION logbook_update_extra_json_fn(IN _id integer, IN _start text, IN
|
||||
FROM api.metrics m,
|
||||
jsonb_each_text(m.metrics)
|
||||
WHERE key ILIKE 'navigation.log'
|
||||
AND time = _start::timestamp without time zone
|
||||
AND time = _start::TIMESTAMPTZ
|
||||
AND vessel_id = current_setting('vessel.id', false)
|
||||
),
|
||||
end_trip as (
|
||||
@@ -310,7 +313,7 @@ CREATE FUNCTION logbook_update_extra_json_fn(IN _id integer, IN _start text, IN
|
||||
FROM api.metrics m,
|
||||
jsonb_each_text(m.metrics)
|
||||
WHERE key ILIKE 'navigation.log'
|
||||
AND time = _end::timestamp without time zone
|
||||
AND time = _end::TIMESTAMPTZ
|
||||
AND vessel_id = current_setting('vessel.id', false)
|
||||
),
|
||||
nm as (
|
||||
@@ -327,7 +330,7 @@ CREATE FUNCTION logbook_update_extra_json_fn(IN _id integer, IN _start text, IN
|
||||
FROM api.metrics m,
|
||||
jsonb_each_text(m.metrics)
|
||||
WHERE key ILIKE 'propulsion.%.runTime'
|
||||
AND time = _start::timestamp without time zone
|
||||
AND time = _start::TIMESTAMPTZ
|
||||
AND vessel_id = current_setting('vessel.id', false)
|
||||
LOOP
|
||||
-- Engine Hours in seconds
|
||||
@@ -339,7 +342,7 @@ CREATE FUNCTION logbook_update_extra_json_fn(IN _id integer, IN _start text, IN
|
||||
FROM api.metrics m,
|
||||
jsonb_each_text(m.metrics)
|
||||
WHERE key ILIKE metric_rec.key
|
||||
AND time = _end::timestamp without time zone
|
||||
AND time = _end::TIMESTAMPTZ
|
||||
AND vessel_id = current_setting('vessel.id', false)
|
||||
),
|
||||
runtime AS (
|
||||
@@ -367,9 +370,11 @@ 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$
|
||||
DECLARE
|
||||
logbook_rec record;
|
||||
from_name varchar;
|
||||
to_name varchar;
|
||||
log_name varchar;
|
||||
from_name text;
|
||||
to_name text;
|
||||
log_name text;
|
||||
from_moorage record;
|
||||
to_moorage record;
|
||||
avg_rec record;
|
||||
geo_rec record;
|
||||
log_settings jsonb;
|
||||
@@ -420,21 +425,22 @@ CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void
|
||||
|
||||
-- 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;
|
||||
SELECT logbook_rec._to_time::TIMESTAMPTZ < logbook_rec._from_time::TIMESTAMPTZ 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;
|
||||
SELECT (logbook_rec._to_time::TIMESTAMPTZ - logbook_rec._from_time::TIMESTAMPTZ) < (100::text||' secs')::interval INTO _invalid_interval;
|
||||
-- if stationary fix data metrics,logbook,stays,moorage
|
||||
IF _invalid_time IS True OR _invalid_distance IS True
|
||||
OR _invalid_interval IS True OR count_metric = avg_rec.count_metric THEN
|
||||
RAISE NOTICE '-> process_logbook_queue_fn invalid logbook data id [%], _invalid_time [%], _invalid_distance [%], _invalid_interval [%], count_metric [%]',
|
||||
logbook_rec.id, _invalid_time, _invalid_distance, _invalid_interval, count_metric;
|
||||
OR _invalid_interval IS True OR count_metric = avg_rec.count_metric
|
||||
OR avg_rec.count_metric <= 2 THEN
|
||||
RAISE NOTICE '-> process_logbook_queue_fn invalid logbook data id [%], _invalid_time [%], _invalid_distance [%], _invalid_interval [%], count_metric_in_zone [%], count_metric_log [%]',
|
||||
logbook_rec.id, _invalid_time, _invalid_distance, _invalid_interval, count_metric, avg_rec.count_metric;
|
||||
-- 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
|
||||
WHERE time >= logbook_rec._from_time::TIMESTAMPTZ
|
||||
AND time <= logbook_rec._to_time::TIMESTAMPTZ
|
||||
AND vessel_id = current_setting('vessel.id', false);
|
||||
-- Update logbook
|
||||
UPDATE api.logbook
|
||||
@@ -459,7 +465,7 @@ CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void
|
||||
-- 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,
|
||||
SET departed = current_stays_departed::TIMESTAMPTZ,
|
||||
active = current_stays_active
|
||||
WHERE vessel_id = current_setting('vessel.id', false)
|
||||
AND id = previous_stays_id;
|
||||
@@ -472,14 +478,19 @@ CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void
|
||||
RETURN;
|
||||
END IF;
|
||||
|
||||
-- Do we have an existing moorage within 300m of the new log
|
||||
-- generate logbook name, concat _from_location and _to_location from moorage name
|
||||
from_moorage := process_lat_lon_fn(logbook_rec._from_lng::NUMERIC, logbook_rec._from_lat::NUMERIC);
|
||||
to_moorage := process_lat_lon_fn(logbook_rec._to_lng::NUMERIC, logbook_rec._to_lat::NUMERIC);
|
||||
SELECT CONCAT(from_moorage.moorage_name, ' to ' , to_moorage.moorage_name) INTO log_name;
|
||||
-- Generate logbook name, concat _from_location and _to_location
|
||||
-- geo reverse _from_lng _from_lat
|
||||
-- geo reverse _to_lng _to_lat
|
||||
geo := reverse_geocode_py_fn('nominatim', logbook_rec._from_lng::NUMERIC, logbook_rec._from_lat::NUMERIC);
|
||||
from_name := geo->>'name';
|
||||
geo := reverse_geocode_py_fn('nominatim', logbook_rec._to_lng::NUMERIC, logbook_rec._to_lat::NUMERIC);
|
||||
to_name := geo->>'name';
|
||||
SELECT CONCAT(from_name, ' to ' , to_name) INTO log_name;
|
||||
--geo := reverse_geocode_py_fn('nominatim', logbook_rec._from_lng::NUMERIC, logbook_rec._from_lat::NUMERIC);
|
||||
--from_name := geo->>'name';
|
||||
--geo := reverse_geocode_py_fn('nominatim', logbook_rec._to_lng::NUMERIC, logbook_rec._to_lat::NUMERIC);
|
||||
--to_name := geo->>'name';
|
||||
--SELECT CONCAT(from_name, ' to ' , to_name) INTO log_name;
|
||||
|
||||
-- Process `propulsion.*.runTime` and `navigation.log`
|
||||
-- Calculate extra json
|
||||
@@ -488,12 +499,14 @@ CREATE OR REPLACE FUNCTION process_logbook_queue_fn(IN _id integer) RETURNS void
|
||||
RAISE NOTICE 'Updating valid logbook entry [%] [%] [%]', logbook_rec.id, logbook_rec._from_time, logbook_rec._to_time;
|
||||
UPDATE api.logbook
|
||||
SET
|
||||
duration = (logbook_rec._to_time::timestamp without time zone - logbook_rec._from_time::timestamp without time zone),
|
||||
duration = (logbook_rec._to_time::TIMESTAMPTZ - logbook_rec._from_time::TIMESTAMPTZ),
|
||||
avg_speed = avg_rec.avg_speed,
|
||||
max_speed = avg_rec.max_speed,
|
||||
max_wind_speed = avg_rec.max_wind_speed,
|
||||
_from = from_name,
|
||||
_to = to_name,
|
||||
_from = from_moorage.moorage_name,
|
||||
_from_moorage_id = from_moorage.moorage_id,
|
||||
_to_moorage_id = to_moorage.moorage_id,
|
||||
_to = to_moorage.moorage_name,
|
||||
name = log_name,
|
||||
track_geom = geo_rec._track_geom,
|
||||
distance = geo_rec._track_distance,
|
||||
@@ -532,7 +545,7 @@ DROP FUNCTION IF EXISTS process_stay_queue_fn;
|
||||
CREATE OR REPLACE FUNCTION process_stay_queue_fn(IN _id integer) RETURNS void AS $process_stay_queue$
|
||||
DECLARE
|
||||
stay_rec record;
|
||||
geo jsonb;
|
||||
moorage record;
|
||||
BEGIN
|
||||
RAISE NOTICE 'process_stay_queue_fn';
|
||||
-- If _id is valid, not NULL
|
||||
@@ -543,9 +556,12 @@ CREATE OR REPLACE FUNCTION process_stay_queue_fn(IN _id integer) RETURNS void AS
|
||||
-- Get the stay record with all necessary fields exist
|
||||
SELECT * INTO stay_rec
|
||||
FROM api.stays
|
||||
WHERE id = _id
|
||||
WHERE active IS false
|
||||
AND departed IS NOT NULL
|
||||
AND arrived IS NOT NULL
|
||||
AND longitude IS NOT NULL
|
||||
AND latitude IS NOT NULL;
|
||||
AND latitude IS NOT NULL
|
||||
AND id = _id;
|
||||
-- Ensure the query is successful
|
||||
IF stay_rec.vessel_id IS NULL THEN
|
||||
RAISE WARNING '-> process_stay_queue_fn invalid stay %', _id;
|
||||
@@ -553,17 +569,40 @@ CREATE OR REPLACE FUNCTION process_stay_queue_fn(IN _id integer) RETURNS void AS
|
||||
END IF;
|
||||
|
||||
PERFORM set_config('vessel.id', stay_rec.vessel_id, false);
|
||||
-- geo reverse _lng _lat
|
||||
geo := reverse_geocode_py_fn('nominatim', stay_rec.longitude::NUMERIC, stay_rec.latitude::NUMERIC);
|
||||
|
||||
RAISE NOTICE 'Updating stay entry [%]', stay_rec.id;
|
||||
-- Do we have an existing moorage within 300m of the new stay
|
||||
moorage := process_lat_lon_fn(stay_rec.longitude::NUMERIC, stay_rec.latitude::NUMERIC);
|
||||
|
||||
RAISE NOTICE '-> process_stay_queue_fn Updating stay entry [%]', stay_rec.id;
|
||||
UPDATE api.stays
|
||||
SET
|
||||
name = coalesce(geo->>'name', null),
|
||||
name = concat(
|
||||
ROUND( EXTRACT(epoch from (stay_rec.departed::TIMESTAMPTZ - stay_rec.arrived::TIMESTAMPTZ)::INTERVAL / 86400) ),
|
||||
' days stay at ',
|
||||
moorage.moorage_name,
|
||||
' in ',
|
||||
RTRIM(TO_CHAR(stay_rec.departed, 'Month')),
|
||||
' ',
|
||||
TO_CHAR(stay_rec.departed, 'YYYY')
|
||||
),
|
||||
moorage_id = moorage.moorage_id,
|
||||
duration = (stay_rec.departed::TIMESTAMPTZ - stay_rec.arrived::TIMESTAMPTZ)::INTERVAL,
|
||||
stay_code = moorage.moorage_type,
|
||||
geog = Geography(ST_MakePoint(stay_rec.longitude, stay_rec.latitude))
|
||||
WHERE id = stay_rec.id;
|
||||
|
||||
-- Notification email/pushover?
|
||||
RAISE NOTICE '-> process_stay_queue_fn Updating moorage entry [%]', moorage.moorage_id;
|
||||
UPDATE api.moorages
|
||||
SET
|
||||
reference_count = (
|
||||
with _from as (select count(*) from api.logbook where _from_moorage_id = moorage.moorage_id),
|
||||
_to as (select count(*) from api.logbook where _to_moorage_id = moorage.moorage_id)
|
||||
select _from.count+_to.count from _from,_to
|
||||
),
|
||||
stay_duration = (
|
||||
select sum(departed-arrived) from api.stays where moorage_id = moorage.moorage_id
|
||||
)
|
||||
WHERE id = moorage.moorage_id;
|
||||
END;
|
||||
$process_stay_queue$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
@@ -572,7 +611,7 @@ COMMENT ON FUNCTION
|
||||
IS 'Update stay details, reverse_geocode_py_fn';
|
||||
|
||||
-- Handle moorage insert or update from stays
|
||||
-- todo valide geography unit
|
||||
-- todo validate geography unit
|
||||
-- https://postgis.net/docs/ST_DWithin.html
|
||||
DROP FUNCTION IF EXISTS process_moorage_queue_fn;
|
||||
CREATE OR REPLACE FUNCTION process_moorage_queue_fn(IN _id integer) RETURNS void AS $process_moorage_queue$
|
||||
@@ -605,44 +644,44 @@ CREATE OR REPLACE FUNCTION process_moorage_queue_fn(IN _id integer) RETURNS void
|
||||
|
||||
PERFORM set_config('vessel.id', stay_rec.vessel_id, false);
|
||||
|
||||
-- Do we have an existing stay within 100m of the new moorage
|
||||
FOR moorage_rec in
|
||||
SELECT
|
||||
*
|
||||
FROM api.moorages
|
||||
WHERE
|
||||
latitude IS NOT NULL
|
||||
AND longitude IS NOT NULL
|
||||
-- Do we have an existing stay within 200m of the new moorage
|
||||
FOR moorage_rec in
|
||||
SELECT
|
||||
*
|
||||
FROM api.moorages
|
||||
WHERE
|
||||
latitude IS NOT NULL
|
||||
AND longitude IS NOT NULL
|
||||
AND geog IS NOT NULL
|
||||
AND ST_DWithin(
|
||||
-- Geography(ST_MakePoint(stay_rec._lng, stay_rec._lat)),
|
||||
AND ST_DWithin(
|
||||
-- Geography(ST_MakePoint(stay_rec._lng, stay_rec._lat)),
|
||||
stay_rec.geog,
|
||||
-- Geography(ST_MakePoint(longitude, latitude)),
|
||||
-- Geography(ST_MakePoint(longitude, latitude)),
|
||||
geog,
|
||||
100 -- in meters ?
|
||||
)
|
||||
ORDER BY id ASC
|
||||
LOOP
|
||||
-- found previous stay within 100m of the new moorage
|
||||
IF moorage_rec.id IS NOT NULL AND moorage_rec.id > 0 THEN
|
||||
RAISE NOTICE 'Found previous stay within 100m of moorage %', moorage_rec;
|
||||
EXIT; -- exit loop
|
||||
END IF;
|
||||
END LOOP;
|
||||
200 -- in meters ?
|
||||
)
|
||||
ORDER BY id ASC
|
||||
LOOP
|
||||
-- found previous stay within 200m of the new moorage
|
||||
IF moorage_rec.id IS NOT NULL AND moorage_rec.id > 0 THEN
|
||||
RAISE NOTICE 'Found previous stay within 200m of moorage %', moorage_rec;
|
||||
EXIT; -- exit loop
|
||||
END IF;
|
||||
END LOOP;
|
||||
|
||||
-- if with in 100m update reference count and stay duration
|
||||
-- else insert new entry
|
||||
IF moorage_rec.id IS NOT NULL AND moorage_rec.id > 0 THEN
|
||||
RAISE NOTICE 'Update moorage %', moorage_rec;
|
||||
UPDATE api.moorages
|
||||
SET
|
||||
reference_count = moorage_rec.reference_count + 1,
|
||||
stay_duration =
|
||||
-- if with in 200m update reference count and stay duration
|
||||
-- else insert new entry
|
||||
IF moorage_rec.id IS NOT NULL AND moorage_rec.id > 0 THEN
|
||||
RAISE NOTICE 'Update moorage %', moorage_rec;
|
||||
UPDATE api.moorages
|
||||
SET
|
||||
reference_count = moorage_rec.reference_count + 1,
|
||||
stay_duration =
|
||||
moorage_rec.stay_duration +
|
||||
(stay_rec.departed::timestamp without time zone - stay_rec.arrived::timestamp without time zone)
|
||||
WHERE id = moorage_rec.id;
|
||||
ELSE
|
||||
RAISE NOTICE 'Insert new moorage entry from stay %', stay_rec;
|
||||
(stay_rec.departed::TIMESTAMPTZ - stay_rec.arrived::TIMESTAMPTZ)
|
||||
WHERE id = moorage_rec.id;
|
||||
ELSE
|
||||
RAISE NOTICE 'Insert new moorage entry from stay %', stay_rec;
|
||||
-- Set the moorage name and country if lat,lon
|
||||
IF stay_rec.longitude IS NOT NULL AND stay_rec.latitude IS NOT NULL THEN
|
||||
geo := reverse_geocode_py_fn('nominatim', stay_rec.longitude::NUMERIC, stay_rec.latitude::NUMERIC);
|
||||
@@ -650,21 +689,21 @@ CREATE OR REPLACE FUNCTION process_moorage_queue_fn(IN _id integer) RETURNS void
|
||||
moorage_rec.country = geo->>'country_code';
|
||||
END IF;
|
||||
-- Insert new moorage from stay
|
||||
INSERT INTO api.moorages
|
||||
(vessel_id, name, country, stay_id, stay_code, stay_duration, reference_count, latitude, longitude, geog)
|
||||
VALUES (
|
||||
INSERT INTO api.moorages
|
||||
(vessel_id, name, country, stay_id, stay_code, stay_duration, reference_count, latitude, longitude, geog)
|
||||
VALUES (
|
||||
stay_rec.vessel_id,
|
||||
coalesce(moorage_rec.name, null),
|
||||
coalesce(moorage_rec.country, null),
|
||||
stay_rec.id,
|
||||
stay_rec.stay_code,
|
||||
(stay_rec.departed::timestamp without time zone - stay_rec.arrived::timestamp without time zone),
|
||||
1, -- default reference_count
|
||||
stay_rec.latitude,
|
||||
stay_rec.longitude,
|
||||
stay_rec.id,
|
||||
stay_rec.stay_code,
|
||||
(stay_rec.departed::TIMESTAMPTZ - stay_rec.arrived::TIMESTAMPTZ),
|
||||
1, -- default reference_count
|
||||
stay_rec.latitude,
|
||||
stay_rec.longitude,
|
||||
Geography(ST_MakePoint(stay_rec.longitude, stay_rec.latitude))
|
||||
);
|
||||
END IF;
|
||||
END IF;
|
||||
|
||||
-- Process badges
|
||||
PERFORM badges_moorages_fn();
|
||||
@@ -1343,11 +1382,11 @@ CREATE OR REPLACE FUNCTION public.process_logbook_valid_fn(IN _id integer) RETUR
|
||||
|
||||
-- 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;
|
||||
SELECT logbook_rec._to_time::TIMESTAMPTZ < logbook_rec._from_time::TIMESTAMPTZ 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;
|
||||
SELECT (logbook_rec._to_time::TIMESTAMPTZ - logbook_rec._from_time::TIMESTAMPTZ) < (100::text||' secs')::interval INTO _invalid_interval;
|
||||
-- if stationary fix data metrics,logbook,stays,moorage
|
||||
IF _invalid_time IS True OR _invalid_distance IS True
|
||||
OR _invalid_interval IS True OR count_metric = avg_rec.count_metric THEN
|
||||
@@ -1356,8 +1395,8 @@ CREATE OR REPLACE FUNCTION public.process_logbook_valid_fn(IN _id integer) RETUR
|
||||
-- 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
|
||||
WHERE time >= logbook_rec._from_time::TIMESTAMPTZ
|
||||
AND time <= logbook_rec._to_time::TIMESTAMPTZ
|
||||
AND vessel_id = current_setting('vessel.id', false);
|
||||
-- Update logbook
|
||||
UPDATE api.logbook
|
||||
@@ -1383,7 +1422,7 @@ CREATE OR REPLACE FUNCTION public.process_logbook_valid_fn(IN _id integer) RETUR
|
||||
-- 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,
|
||||
SET departed = current_stays_departed::TIMESTAMPTZ,
|
||||
active = current_stays_active
|
||||
WHERE vessel_id = current_setting('vessel.id', false)
|
||||
AND id = previous_stays_id;
|
||||
@@ -1403,20 +1442,145 @@ COMMENT ON FUNCTION
|
||||
public.process_logbook_queue_fn
|
||||
IS 'Avoid/ignore/delete logbook stationary movement or time sync issue';
|
||||
|
||||
DROP FUNCTION IF EXISTS process_lat_lon_fn;
|
||||
CREATE OR REPLACE FUNCTION process_lat_lon_fn(IN lon NUMERIC, IN lat NUMERIC,
|
||||
OUT moorage_id INTEGER,
|
||||
OUT moorage_type INTEGER,
|
||||
OUT moorage_name TEXT,
|
||||
OUT moorage_country TEXT
|
||||
) AS $process_lat_lon$
|
||||
DECLARE
|
||||
stay_rec record;
|
||||
--moorage_id INTEGER := NULL;
|
||||
--moorage_type INTEGER := 1; -- Unknown
|
||||
--moorage_name TEXT := NULL;
|
||||
--moorage_country TEXT := NULL;
|
||||
existing_rec record;
|
||||
geo jsonb;
|
||||
overpass jsonb;
|
||||
BEGIN
|
||||
RAISE NOTICE 'process_lat_lon_fn';
|
||||
-- If _id is valid, not NULL
|
||||
IF lon IS NULL OR lat IS NULL THEN
|
||||
RAISE WARNING '-> process_lat_lon_fn invalid input lon,lat %', _id;
|
||||
--return NULL;
|
||||
END IF;
|
||||
|
||||
-- Do we have an existing moorages within 300m of the new stay
|
||||
FOR existing_rec in
|
||||
SELECT
|
||||
*
|
||||
FROM api.moorages m
|
||||
WHERE
|
||||
m.latitude IS NOT NULL
|
||||
AND m.longitude IS NOT NULL
|
||||
AND m.geog IS NOT NULL
|
||||
AND ST_DWithin(
|
||||
Geography(ST_MakePoint(m.longitude, m.latitude)),
|
||||
Geography(ST_MakePoint(lon, lat)),
|
||||
300 -- in meters
|
||||
)
|
||||
AND m.vessel_id = current_setting('vessel.id', false)
|
||||
ORDER BY id ASC
|
||||
LOOP
|
||||
-- found previous stay within 300m of the new moorage
|
||||
IF existing_rec.id IS NOT NULL AND existing_rec.id > 0 THEN
|
||||
RAISE NOTICE '-> process_lat_lon_fn found previous moorages within 300m %', existing_rec;
|
||||
EXIT; -- exit loop
|
||||
END IF;
|
||||
END LOOP;
|
||||
|
||||
-- if with in 200m use existing name and stay_code
|
||||
-- else insert new entry
|
||||
IF existing_rec.id IS NOT NULL AND existing_rec.id > 0 THEN
|
||||
RAISE NOTICE '-> process_lat_lon_fn found close by moorage using existing name and stay_code %', existing_rec;
|
||||
moorage_id := existing_rec.id;
|
||||
moorage_name := existing_rec.name;
|
||||
moorage_type := existing_rec.stay_code;
|
||||
ELSE
|
||||
RAISE NOTICE '-> process_lat_lon_fn create new moorage';
|
||||
-- query overpass api to guess moorage type
|
||||
overpass := overpass_py_fn(lon::NUMERIC, lat::NUMERIC);
|
||||
RAISE NOTICE '-> process_lat_lon_fn overpass name:[%] type:[%]', overpass->'name', overpass->'seamark:type';
|
||||
moorage_type = 1; -- Unknown
|
||||
IF overpass->>'seamark:type' = 'harbour' AND overpass->>'seamark:harbour:category' = 'marina' then
|
||||
moorage_type = 4; -- Dock
|
||||
ELSIF overpass->>'seamark:type' = 'mooring' AND overpass->>'seamark:mooring:category' = 'buoy' then
|
||||
moorage_type = 3; -- Mooring Buoy
|
||||
ELSIF overpass->>'seamark:type' ~ '(anchorage|anchor_berth|berth)' OR overpass->>'natural' ~ '(bay|beach)' then
|
||||
moorage_type = 2; -- Anchor
|
||||
ELSIF overpass->>'seamark:type' = 'mooring' then
|
||||
moorage_type = 3; -- Mooring Buoy
|
||||
ELSIF overpass->>'leisure' = 'marina' then
|
||||
moorage_type = 4; -- Dock
|
||||
END IF;
|
||||
IF overpass->>'name:en' IS NOT NULL then
|
||||
moorage_name = overpass->>'name:en';
|
||||
ELSIF overpass->>'name' IS NOT NULL then
|
||||
moorage_name = overpass->>'name';
|
||||
ELSE
|
||||
-- geo reverse _lng _lat
|
||||
geo := reverse_geocode_py_fn('nominatim', lon::NUMERIC, lat::NUMERIC);
|
||||
moorage_name := geo->>'name';
|
||||
moorage_country := geo->>'country_code';
|
||||
END IF;
|
||||
RAISE NOTICE '-> process_lat_lon_fn output name:[%] type:[%]', moorage_name, moorage_type;
|
||||
RAISE NOTICE '-> process_lat_lon_fn insert new moorage for [%] name:[%] type:[%]', current_setting('vessel.id', false), moorage_name, moorage_type;
|
||||
-- Insert new moorage from stay
|
||||
INSERT INTO api.moorages
|
||||
(vessel_id, name, country, stay_code, reference_count, latitude, longitude, geog, overpass, nominatim)
|
||||
VALUES (
|
||||
current_setting('vessel.id', false),
|
||||
coalesce(moorage_name, null),
|
||||
coalesce(moorage_country, null),
|
||||
moorage_type,
|
||||
1,
|
||||
lat,
|
||||
lon,
|
||||
Geography(ST_MakePoint(lon, lat)),
|
||||
coalesce(overpass, null),
|
||||
coalesce(geo, null)
|
||||
) returning id into moorage_id;
|
||||
-- Add moorage entry to process queue for reference
|
||||
--INSERT INTO process_queue (channel, payload, stored, ref_id, processed)
|
||||
-- VALUES ('new_moorage', moorage_id, now(), current_setting('vessel.id', true), now());
|
||||
END IF;
|
||||
--return json_build_object(
|
||||
-- 'id', moorage_id,
|
||||
-- 'name', moorage_name,
|
||||
-- 'type', moorage_type
|
||||
-- )::jsonb;
|
||||
END;
|
||||
$process_lat_lon$ LANGUAGE plpgsql;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.process_lat_lon_fn
|
||||
IS 'Add or Update moorage base on lat/lon';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- TODO add alert monitoring for Battery
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- PostgREST API pre-request check
|
||||
-- TODO db-pre-request = "public.check_jwt"
|
||||
-- Prevent unregister user or unregister vessel access
|
||||
-- require to set in configuration, eg: db-pre-request = "public.check_jwt"
|
||||
CREATE OR REPLACE FUNCTION public.check_jwt() RETURNS void AS $$
|
||||
-- Prevent unregister user or unregister vessel access
|
||||
-- Allow anonymous access
|
||||
DECLARE
|
||||
_role name;
|
||||
_email text;
|
||||
_mmsi name;
|
||||
anonymous record;
|
||||
_path name;
|
||||
_vid text;
|
||||
_vname text;
|
||||
boat TEXT;
|
||||
_pid INTEGER := 0; -- public_id
|
||||
_pvessel TEXT := NULL; -- public_type
|
||||
_ptype TEXT := NULL; -- public_type
|
||||
_ppath BOOLEAN := False; -- public_path
|
||||
_pvalid BOOLEAN := False; -- public_valid
|
||||
_pheader text := NULL; -- public_header
|
||||
valid_public_type BOOLEAN := False;
|
||||
account_rec record;
|
||||
vessel_rec record;
|
||||
BEGIN
|
||||
@@ -1444,10 +1608,14 @@ BEGIN
|
||||
END IF;
|
||||
-- Set session variables
|
||||
PERFORM set_config('user.id', account_rec.user_id, false);
|
||||
--RAISE WARNING 'req path %', current_setting('request.path', true);
|
||||
-- Function allow without defined vessel
|
||||
-- openapi doc, user settings, otp code and vessel registration
|
||||
SELECT current_setting('request.path', true) into _path;
|
||||
--RAISE WARNING 'req path %', current_setting('request.path', true);
|
||||
-- Function allow without defined vessel like for anonymous role
|
||||
IF _path ~ '^\/rpc\/(login|signup|recover|reset)$' THEN
|
||||
RETURN;
|
||||
END IF;
|
||||
-- Function allow without defined vessel as user role
|
||||
-- openapi doc, user settings, otp code and vessel registration
|
||||
IF _path = '/rpc/settings_fn'
|
||||
OR _path = '/rpc/register_vessel'
|
||||
OR _path = '/rpc/update_user_preferences_fn'
|
||||
@@ -1464,10 +1632,10 @@ BEGIN
|
||||
-- check if boat exist yet?
|
||||
IF vessel_rec.owner_email IS NULL THEN
|
||||
-- Return http status code 551 with message
|
||||
RAISE sqlstate 'PT551' using
|
||||
message = 'Vessel Required',
|
||||
detail = 'Invalid vessel',
|
||||
hint = 'Unknown vessel';
|
||||
RAISE sqlstate 'PT551' using
|
||||
message = 'Vessel Required',
|
||||
detail = 'Invalid vessel',
|
||||
hint = 'Unknown vessel';
|
||||
--RETURN; -- ignore if not exist
|
||||
END IF;
|
||||
-- Redundant?
|
||||
@@ -1497,12 +1665,88 @@ BEGIN
|
||||
PERFORM set_config('vessel.name', vessel_rec.name, false);
|
||||
--RAISE WARNING 'public.check_jwt() user_role vessel.name %', current_setting('vessel.name', false);
|
||||
--RAISE WARNING 'public.check_jwt() user_role vessel.id %', current_setting('vessel.id', false);
|
||||
ELSIF _role = 'api_anonymous' THEN
|
||||
RAISE WARNING 'public.check_jwt() api_anonymous';
|
||||
-- Check if path is the a valid allow anonymous path
|
||||
SELECT current_setting('request.path', true) ~ '^/(logs_view|log_view|rpc/timelapse_fn|monitoring_view|stats_logs_view|stats_moorages_view|rpc/stats_logs_fn)$' INTO _ppath;
|
||||
if _ppath is True then
|
||||
-- Check is custom header is present and valid
|
||||
SELECT current_setting('request.headers', true)::json->>'x-is-public' into _pheader;
|
||||
RAISE WARNING 'public.check_jwt() api_anonymous _pheader [%]', _pheader;
|
||||
if _pheader is null then
|
||||
RAISE EXCEPTION 'Invalid public_header'
|
||||
USING HINT = 'Stop being so evil and maybe you can log in';
|
||||
end if;
|
||||
SELECT convert_from(decode(_pheader, 'base64'), 'utf-8')
|
||||
~ '\w+,public_(logs|logs_list|stats|timelapse|monitoring),\d+$' into _pvalid;
|
||||
RAISE WARNING 'public.check_jwt() api_anonymous _pvalid [%]', _pvalid;
|
||||
if _pvalid is null or _pvalid is False then
|
||||
RAISE EXCEPTION 'Invalid public_valid'
|
||||
USING HINT = 'Stop being so evil and maybe you can log in';
|
||||
end if;
|
||||
WITH regex AS (
|
||||
SELECT regexp_match(
|
||||
convert_from(
|
||||
decode(_pheader, 'base64'), 'utf-8'),
|
||||
'(\w+),(public_(logs|logs_list|stats|timelapse|monitoring)),(\d+)$') AS match
|
||||
)
|
||||
SELECT match[1], match[2], match[4] into _pvessel, _ptype, _pid
|
||||
FROM regex;
|
||||
RAISE WARNING 'public.check_jwt() api_anonymous [%] [%] [%]', _pvessel, _ptype, _pid;
|
||||
if _pvessel is not null and _ptype is not null then
|
||||
-- Everything seem fine, get the vessel_id base on the vessel name.
|
||||
SELECT _ptype::name = any(enum_range(null::public_type)::name[]) INTO valid_public_type;
|
||||
IF valid_public_type IS False THEN
|
||||
-- Ignore entry if type is invalid
|
||||
RAISE EXCEPTION 'Invalid public_type'
|
||||
USING HINT = 'Stop being so evil and maybe you can log in';
|
||||
END IF;
|
||||
-- Check if boat name match public_vessel name
|
||||
boat := '^' || _pvessel || '$';
|
||||
IF _ptype ~ '^public_(logs|timelapse)$' AND _pid IS NOT NULL THEN
|
||||
WITH log as (
|
||||
SELECT vessel_id from api.logbook l where l.id = _pid
|
||||
)
|
||||
SELECT v.vessel_id, v.name into anonymous
|
||||
FROM auth.accounts a, auth.vessels v, jsonb_each_text(a.preferences) as prefs, log l
|
||||
WHERE v.vessel_id = l.vessel_id
|
||||
AND a.email = v.owner_email
|
||||
AND a.preferences->>'public_vessel'::text ~* boat
|
||||
AND prefs.key = _ptype::TEXT
|
||||
AND prefs.value::BOOLEAN = true;
|
||||
RAISE WARNING '-> ispublic_fn public_logs output boat:[%], type:[%], result:[%]', _pvessel, _ptype, anonymous;
|
||||
IF anonymous.vessel_id IS NOT NULL THEN
|
||||
PERFORM set_config('vessel.id', anonymous.vessel_id, false);
|
||||
PERFORM set_config('vessel.name', anonymous.name, false);
|
||||
RETURN;
|
||||
END IF;
|
||||
ELSE
|
||||
SELECT v.vessel_id, v.name into anonymous
|
||||
FROM auth.accounts a, auth.vessels v, jsonb_each_text(a.preferences) as prefs
|
||||
WHERE a.email = v.owner_email
|
||||
AND a.preferences->>'public_vessel'::text ~* boat
|
||||
AND prefs.key = _ptype::TEXT
|
||||
AND prefs.value::BOOLEAN = true;
|
||||
RAISE WARNING '-> ispublic_fn output boat:[%], type:[%], result:[%]', _pvessel, _ptype, anonymous;
|
||||
IF anonymous.vessel_id IS NOT NULL THEN
|
||||
PERFORM set_config('vessel.id', anonymous.vessel_id, false);
|
||||
PERFORM set_config('vessel.name', anonymous.name, false);
|
||||
RETURN;
|
||||
END IF;
|
||||
END IF;
|
||||
RAISE sqlstate 'PT404' using message = 'unknown resource';
|
||||
END IF; -- end anonymous path
|
||||
END IF;
|
||||
ELSIF _role <> 'api_anonymous' THEN
|
||||
RAISE EXCEPTION 'Invalid role'
|
||||
USING HINT = 'Stop being so evil and maybe you can log in';
|
||||
END IF;
|
||||
END
|
||||
$$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.check_jwt
|
||||
IS 'PostgREST API db-pre-request check, set_config according to role (api_anonymous,vessel_role,user_role)';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- Function to trigger cron_jobs using API for tests.
|
||||
@@ -1515,7 +1759,7 @@ BEGIN
|
||||
perform public.cron_process_monitor_online_fn();
|
||||
perform public.cron_process_new_logbook_fn();
|
||||
perform public.cron_process_new_stay_fn();
|
||||
perform public.cron_process_new_moorage_fn();
|
||||
--perform public.cron_process_new_moorage_fn();
|
||||
perform public.cron_process_monitor_offline_fn();
|
||||
END
|
||||
$$ language plpgsql;
|
||||
|
@@ -79,9 +79,9 @@ COMMENT ON FUNCTION
|
||||
|
||||
CREATE OR REPLACE FUNCTION public.istimestamptz(text) RETURNS BOOLEAN AS
|
||||
$isdate$
|
||||
DECLARE x TIMESTAMP WITHOUT TIME ZONE;
|
||||
DECLARE x TIMESTAMPTZ;
|
||||
BEGIN
|
||||
x = $1::TIMESTAMP WITHOUT TIME ZONE;
|
||||
x = $1::TIMESTAMPTZ;
|
||||
RETURN TRUE;
|
||||
EXCEPTION WHEN others THEN
|
||||
RETURN FALSE;
|
||||
@@ -92,7 +92,7 @@ LANGUAGE plpgsql IMMUTABLE;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.istimestamptz
|
||||
IS 'Check typeof value is TIMESTAMP WITHOUT TIME ZONE';
|
||||
IS 'Check typeof value is TIMESTAMPTZ';
|
||||
|
||||
---------------------------------------------------------------------------
|
||||
-- JSON helpers
|
||||
|
@@ -42,9 +42,10 @@ AS $reverse_geocode_py$
|
||||
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 = {"Accept-Language": "en-US,en;q=0.5"}, params=payload)
|
||||
r = requests.get(url, headers=headers, params=payload)
|
||||
|
||||
# Parse response
|
||||
# If name is null fallback to address field tags: neighbourhood,suburb
|
||||
@@ -76,7 +77,7 @@ AS $reverse_geocode_py$
|
||||
else:
|
||||
if (zoom == 15):
|
||||
plpy.notice('georeverse recursive retry with lower zoom than:[{}], Response [{}]'.format(zoom , r.json()))
|
||||
return georeverse(geocoder, lon, lat, 14)
|
||||
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)
|
||||
@@ -356,6 +357,10 @@ 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
|
||||
@@ -373,16 +378,14 @@ AS $reverse_geoip_py$
|
||||
url = f'https://ipapi.co/{_ip}/json/'
|
||||
r = requests.get(url)
|
||||
#print(r.text)
|
||||
# Return something boolean?
|
||||
plpy.warning('IP [{}] [{}]'.format(_ip, r.status_code))
|
||||
#plpy.notice('IP [{}] [{}]'.format(_ip, r.status_code))
|
||||
if r.status_code == 200:
|
||||
#plpy.notice('Got [{}] [{}]'.format(r.text, r.status_code))
|
||||
return r.text;
|
||||
return r.json();
|
||||
else:
|
||||
plpy.error('Failed to get ip details')
|
||||
return '{}'
|
||||
$reverse_geoip_py$ LANGUAGE plpython3u;
|
||||
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
public.reverse_geoip_py_fn
|
||||
@@ -432,3 +435,50 @@ IMMUTABLE STRICT;
|
||||
COMMENT ON FUNCTION
|
||||
public.geojson_py_fn
|
||||
IS 'Parse geojson using plpython3u (should be done in PGSQL)';
|
||||
|
||||
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/1D91
|
||||
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];
|
||||
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 qt;
|
||||
""".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';
|
||||
|
@@ -21,7 +21,7 @@ CREATE EXTENSION IF NOT EXISTS "pgcrypto"; -- provides cryptographic functions
|
||||
|
||||
DROP TABLE IF EXISTS auth.accounts CASCADE;
|
||||
CREATE TABLE IF NOT EXISTS auth.accounts (
|
||||
public_id SERIAL UNIQUE NOT NULL,
|
||||
public_id INT UNIQUE NOT NULL GENERATED ALWAYS AS IDENTITY,
|
||||
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),
|
||||
@@ -29,9 +29,9 @@ CREATE TABLE IF NOT EXISTS auth.accounts (
|
||||
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 TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
connected_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
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),
|
||||
@@ -42,11 +42,7 @@ COMMENT ON TABLE
|
||||
auth.accounts
|
||||
IS 'users account table';
|
||||
-- Indexes
|
||||
-- is unused index?
|
||||
--CREATE INDEX accounts_role_idx ON auth.accounts (role);
|
||||
CREATE INDEX accounts_preferences_idx ON auth.accounts USING GIN (preferences);
|
||||
CREATE INDEX accounts_public_id_idx ON auth.accounts (public_id);
|
||||
COMMENT ON COLUMN auth.accounts.public_id IS 'User public_id to allow mapping for anonymous access, could be use as well for as Grafana orgId';
|
||||
COMMENT ON COLUMN auth.accounts.first IS 'User first name with CONSTRAINT CHECK';
|
||||
COMMENT ON COLUMN auth.accounts.last IS 'User last name with CONSTRAINT CHECK';
|
||||
|
||||
@@ -61,7 +57,7 @@ COMMENT ON TRIGGER accounts_moddatetime
|
||||
|
||||
DROP TABLE IF EXISTS auth.vessels;
|
||||
CREATE TABLE IF NOT EXISTS auth.vessels (
|
||||
vessel_id TEXT NOT NULL UNIQUE DEFAULT RIGHT(gen_random_uuid()::text, 12),
|
||||
vessel_id TEXT NOT NULL UNIQUE DEFAULT RIGHT(gen_random_uuid()::text, 12),
|
||||
-- user_id TEXT NOT NULL REFERENCES auth.accounts(user_id) ON DELETE RESTRICT,
|
||||
owner_email CITEXT PRIMARY KEY REFERENCES auth.accounts(email) ON DELETE RESTRICT,
|
||||
-- mmsi TEXT UNIQUE, -- Should be a numeric range between 100000000 and 800000000.
|
||||
@@ -69,8 +65,8 @@ CREATE TABLE IF NOT EXISTS auth.vessels (
|
||||
name TEXT NOT NULL CHECK (length(name) >= 3 AND length(name) < 512),
|
||||
-- pass text not null check (length(pass) < 512), -- unused
|
||||
role name not null check (length(role) < 512),
|
||||
created_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMP WITHOUT TIME ZONE NOT NULL DEFAULT NOW()
|
||||
created_at TIMESTAMPTZ NOT NULL DEFAULT NOW(),
|
||||
updated_at TIMESTAMPTZ NOT NULL DEFAULT NOW()
|
||||
-- CONSTRAINT valid_length_mmsi CHECK (length(mmsi) < 10 OR length(mmsi) = 0)
|
||||
CONSTRAINT valid_range_mmsi CHECK (mmsi > 100000000 AND mmsi < 800000000)
|
||||
);
|
||||
@@ -79,10 +75,6 @@ COMMENT ON TABLE
|
||||
auth.vessels
|
||||
IS 'vessels table link to accounts email user_id column';
|
||||
-- Indexes
|
||||
-- is unused index?
|
||||
--CREATE INDEX vessels_role_idx ON auth.vessels (role);
|
||||
-- is unused index?
|
||||
--CREATE INDEX vessels_name_idx ON auth.vessels (name);
|
||||
CREATE INDEX vessels_vesselid_idx ON auth.vessels (vessel_id);
|
||||
|
||||
CREATE TRIGGER vessels_moddatetime
|
||||
@@ -112,12 +104,26 @@ 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;
|
||||
@@ -128,6 +134,18 @@ create constraint trigger ensure_vessel_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 $$
|
||||
|
@@ -20,7 +20,16 @@ COMMENT ON COLUMN api.metadata.vessel_id IS 'Link auth.vessels with api.metadata
|
||||
|
||||
-- REFERENCE ship type with AIS type ?
|
||||
-- REFERENCE mmsi MID with country ?
|
||||
|
||||
ALTER TABLE api.logbook ADD FOREIGN KEY (_from_moorage_id) REFERENCES api.moorages(id) ON DELETE RESTRICT;
|
||||
COMMENT ON COLUMN api.logbook._from_moorage_id IS 'Link api.moorages with api.logbook via FOREIGN KEY and REFERENCES';
|
||||
ALTER TABLE api.logbook ADD FOREIGN KEY (_to_moorage_id) REFERENCES api.moorages(id) ON DELETE RESTRICT;
|
||||
COMMENT ON COLUMN api.logbook._to_moorage_id IS 'Link api.moorages with api.logbook via FOREIGN KEY and REFERENCES';
|
||||
ALTER TABLE api.stays ADD FOREIGN KEY (moorage_id) REFERENCES api.moorages(id) ON DELETE RESTRICT;
|
||||
COMMENT ON COLUMN api.stays.moorage_id IS 'Link api.moorages with api.stays via FOREIGN KEY and REFERENCES';
|
||||
ALTER TABLE api.stays ADD FOREIGN KEY (stay_code) REFERENCES api.stays_at(stay_code) ON DELETE RESTRICT;
|
||||
COMMENT ON COLUMN api.stays.stay_code IS 'Link api.stays_at with api.stays via FOREIGN KEY and REFERENCES';
|
||||
ALTER TABLE api.moorages ADD FOREIGN KEY (stay_code) REFERENCES api.stays_at(stay_code) ON DELETE RESTRICT;
|
||||
COMMENT ON COLUMN api.moorages.stay_code IS 'Link api.stays_at with api.moorages via FOREIGN KEY and REFERENCES';
|
||||
|
||||
-- List vessel
|
||||
--TODO add geojson with position
|
||||
@@ -37,10 +46,10 @@ CREATE OR REPLACE VIEW api.vessels_view WITH (security_invoker=true,security_bar
|
||||
SELECT
|
||||
v.name as name,
|
||||
v.mmsi as mmsi,
|
||||
v.created_at::timestamp(0) as created_at,
|
||||
v.created_at as created_at,
|
||||
m.last_contact as last_contact,
|
||||
((NOW() AT TIME ZONE 'UTC' - m.last_contact::timestamp without time zone) > INTERVAL '70 MINUTES') as offline,
|
||||
(NOW() AT TIME ZONE 'UTC' - m.last_contact::timestamp without time zone) as duration
|
||||
((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
|
||||
@@ -98,9 +107,9 @@ AS $vessel$
|
||||
jsonb_build_object(
|
||||
'name', coalesce(m.name, null),
|
||||
'mmsi', coalesce(m.mmsi, null),
|
||||
'created_at', v.created_at::timestamp(0),
|
||||
'first_contact', coalesce(m.created_at::timestamp(0), null),
|
||||
'last_contact', coalesce(m.time::timestamp(0), 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
|
||||
@@ -140,12 +149,11 @@ AS $user_settings$
|
||||
from (
|
||||
select a.email, a.first, a.last, a.preferences, a.created_at,
|
||||
INITCAP(CONCAT (LEFT(first, 1), ' ', last)) AS username,
|
||||
public.has_vessel_fn() as has_vessel,
|
||||
public.has_vessel_fn() as has_vessel
|
||||
--public.has_vessel_metadata_fn() as has_vessel_metadata,
|
||||
a.public_id
|
||||
from auth.accounts a
|
||||
where email = current_setting('user.email')
|
||||
) row;
|
||||
) row;
|
||||
END;
|
||||
$user_settings$ language plpgsql security definer;
|
||||
-- Description
|
||||
@@ -286,16 +294,17 @@ 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_stats');
|
||||
CREATE FUNCTION api.ispublic_fn(IN id INTEGER, IN _type public_type) RETURNS BOOLEAN AS $ispublic$
|
||||
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
|
||||
_id INTEGER := id;
|
||||
rec record;
|
||||
vessel TEXT := '^' || boat || '$';
|
||||
anonymous BOOLEAN := False;
|
||||
valid_public_type BOOLEAN := False;
|
||||
public_logs BOOLEAN := False;
|
||||
BEGIN
|
||||
-- If _id is is not NULL and > 0
|
||||
IF _id IS NULL OR _id < 1 THEN
|
||||
RAISE WARNING '-> ispublic_fn invalid input %', _id;
|
||||
-- If boat is not NULL
|
||||
IF boat IS NULL THEN
|
||||
RAISE WARNING '-> ispublic_fn invalid input %', boat;
|
||||
RETURN False;
|
||||
END IF;
|
||||
-- Check if public_type is valid enum
|
||||
@@ -306,30 +315,35 @@ BEGIN
|
||||
RETURN False;
|
||||
END IF;
|
||||
|
||||
IF _type = 'public_logs' THEN
|
||||
IF _type ~ '^public_(logs|timelapse)$' AND _id IS NOT NULL THEN
|
||||
WITH log as (
|
||||
select vessel_id from api.logbook l where l.id = _id
|
||||
SELECT vessel_id from api.logbook l where l.id = _id
|
||||
)
|
||||
SELECT (l.vessel_id) is not null into rec
|
||||
--SELECT l.vessel_id, 'email', 'settings', a.preferences
|
||||
FROM auth.accounts a, auth.vessels v, jsonb_each_text(a.preferences), log l
|
||||
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 key = 'public_logs'::TEXT
|
||||
AND value::BOOLEAN = true;
|
||||
IF FOUND THEN
|
||||
RETURN True;
|
||||
END IF;
|
||||
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 (a.email) is not null into rec
|
||||
--SELECT a.email, a.preferences
|
||||
FROM auth.accounts a, jsonb_each_text(a.preferences)
|
||||
WHERE a.public_id = _id
|
||||
AND key = _type::TEXT
|
||||
AND value::BOOLEAN = true;
|
||||
IF FOUND THEN
|
||||
RETURN True;
|
||||
END IF;
|
||||
SELECT EXISTS (
|
||||
SELECT a.email
|
||||
FROM auth.accounts a, jsonb_each_text(a.preferences) as prefs
|
||||
WHERE a.preferences->>'public_vessel'::text ~* vessel
|
||||
AND prefs.key = _type::TEXT
|
||||
AND prefs.value::BOOLEAN = true
|
||||
) into anonymous;
|
||||
RAISE WARNING '-> ispublic_fn output boat:[%], type:[%], result:[%]', boat, _type, anonymous;
|
||||
IF anonymous IS True THEN
|
||||
RETURN True;
|
||||
END IF;
|
||||
END IF;
|
||||
RETURN False;
|
||||
END
|
||||
@@ -337,4 +351,4 @@ $ispublic$ language plpgsql security definer;
|
||||
-- Description
|
||||
COMMENT ON FUNCTION
|
||||
api.ispublic_fn
|
||||
IS 'Is web page publicly accessible?';
|
||||
IS 'Is web page publicly accessible by register boat name and/or logbook id';
|
||||
|
@@ -12,8 +12,8 @@ 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 VARCHAR(10) NOT NULL,
|
||||
otp_timestamp TIMESTAMP WITHOUT TIME ZONE DEFAULT NOW(),
|
||||
otp_pass TEXT NOT NULL,
|
||||
otp_timestamp TIMESTAMPTZ DEFAULT NOW(),
|
||||
otp_tries SMALLINT NOT NULL DEFAULT '0'
|
||||
);
|
||||
-- Description
|
||||
|
@@ -38,7 +38,17 @@ grant execute on function api.pushover_fn(text,text) to api_anonymous;
|
||||
grant execute on function api.telegram_fn(text,text) to api_anonymous;
|
||||
grant execute on function api.telegram_otp_fn(text) to api_anonymous;
|
||||
--grant execute on function api.generate_otp_fn(text) to api_anonymous;
|
||||
grant execute on function api.ispublic_fn(integer,public_type) to api_anonymous;
|
||||
grant execute on function api.ispublic_fn(text,text,integer) to api_anonymous;
|
||||
grant execute on function api.timelapse_fn to api_anonymous;
|
||||
-- Allow read on TABLES on API schema
|
||||
--GRANT SELECT ON TABLE api.metrics,api.logbook,api.moorages,api.stays,api.metadata,api.stays_at TO api_anonymous;
|
||||
-- Allow read on VIEWS on API schema
|
||||
--GRANT SELECT ON TABLE api.logs_view,api.moorages_view,api.stays_view TO api_anonymous;
|
||||
--GRANT SELECT ON TABLE api.log_view,api.moorage_view,api.stay_view,api.vessels_view TO api_anonymous;
|
||||
GRANT SELECT ON ALL TABLES IN SCHEMA api TO api_anonymous;
|
||||
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public TO api_anonymous;
|
||||
--grant execute on function public.st_asgeojson(record,text,integer,boolean) to api_anonymous;
|
||||
--grant execute on function public.st_makepoint(float,float) to api_anonymous;
|
||||
|
||||
-- authenticator
|
||||
-- login role
|
||||
@@ -97,9 +107,11 @@ GRANT SELECT ON TABLE public.process_queue TO user_role;
|
||||
-- To check?
|
||||
GRANT SELECT ON TABLE auth.vessels TO user_role;
|
||||
-- Allow users to update certain columns on specific TABLES on API schema
|
||||
GRANT UPDATE (name, notes) ON api.logbook TO user_role;
|
||||
GRANT UPDATE (name, notes, stay_code) ON api.stays TO user_role;
|
||||
GRANT UPDATE (name, _from, _to, notes) ON api.logbook TO user_role;
|
||||
GRANT UPDATE (name, notes, stay_code, active, departed) ON api.stays TO user_role;
|
||||
GRANT UPDATE (name, notes, stay_code, home_flag) ON api.moorages TO user_role;
|
||||
-- Allow users to remove logs and stays
|
||||
GRANT DELETE ON api.logbook,api.stays,api.moorages TO user_role;
|
||||
-- Allow EXECUTE on all FUNCTIONS on API and public schema
|
||||
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA api TO user_role;
|
||||
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public TO user_role;
|
||||
@@ -115,6 +127,7 @@ GRANT SELECT ON TABLE api.stats_logs_view TO user_role;
|
||||
GRANT SELECT ON TABLE api.stats_moorages_view TO user_role;
|
||||
GRANT SELECT ON TABLE api.eventlogs_view TO user_role;
|
||||
GRANT SELECT ON TABLE api.vessels_view TO user_role;
|
||||
GRANT SELECT ON TABLE api.moorages_stays_view TO user_role;
|
||||
|
||||
-- Vessel:
|
||||
-- nologin
|
||||
@@ -137,7 +150,8 @@ GRANT EXECUTE ON FUNCTION public.trip_in_progress_fn(text) to vessel_role;
|
||||
GRANT EXECUTE ON FUNCTION public.stay_in_progress_fn(text) to vessel_role;
|
||||
-- hypertable get_partition_hash ?!?
|
||||
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA _timescaledb_internal TO vessel_role;
|
||||
|
||||
-- on metrics st_makepoint
|
||||
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public TO vessel_role;
|
||||
|
||||
--- Scheduler:
|
||||
-- TODO: currently cron function are run as super user, switch to scheduler role.
|
||||
@@ -209,6 +223,10 @@ CREATE POLICY api_scheduler_role ON api.metrics TO scheduler
|
||||
CREATE POLICY grafana_role ON api.metrics TO grafana
|
||||
USING (vessel_id = current_setting('vessel.id', false))
|
||||
WITH CHECK (false);
|
||||
-- Allow anonymous to select based on the vessel.id
|
||||
CREATE POLICY api_anonymous_role ON api.metrics TO api_anonymous
|
||||
USING (vessel_id = current_setting('vessel.id', false))
|
||||
WITH CHECK (false);
|
||||
|
||||
-- Be sure to enable row level security on the table
|
||||
ALTER TABLE api.logbook ENABLE ROW LEVEL SECURITY;
|
||||
@@ -233,6 +251,10 @@ CREATE POLICY api_scheduler_role ON api.logbook TO scheduler
|
||||
CREATE POLICY grafana_role ON api.logbook TO grafana
|
||||
USING (vessel_id = current_setting('vessel.id', false))
|
||||
WITH CHECK (false);
|
||||
-- Allow anonymous to select based on the vessel.id
|
||||
CREATE POLICY api_anonymous_role ON api.logbook TO api_anonymous
|
||||
USING (vessel_id = current_setting('vessel.id', false))
|
||||
WITH CHECK (false);
|
||||
|
||||
-- Be sure to enable row level security on the table
|
||||
ALTER TABLE api.stays ENABLE ROW LEVEL SECURITY;
|
||||
|
@@ -19,7 +19,7 @@ SELECT cron.schedule('cron_new_stay', '*/6 * * * *', 'select public.cron_process
|
||||
--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()');
|
||||
--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 10 minute job cron_process_monitor_offline_fn
|
||||
|
@@ -18,7 +18,7 @@ select current_database();
|
||||
\c signalk
|
||||
|
||||
CREATE TABLE public.ne_10m_geography_marine_polys (
|
||||
gid serial4 NOT NULL,
|
||||
gid INT GENERATED ALWAYS AS IDENTITY NOT NULL,
|
||||
featurecla TEXT NULL,
|
||||
"name" TEXT NULL,
|
||||
namealt TEXT NULL,
|
||||
|
@@ -1 +1 @@
|
||||
0.4.1
|
||||
0.5.0
|
||||
|
File diff suppressed because one or more lines are too long
@@ -59,7 +59,7 @@ const fs = require('fs');
|
||||
user_views: [
|
||||
// not processed yet, { url: '/stays_view', res_body_length: 1},
|
||||
// not processed yet, { url: '/moorages_view', res_body_length: 1},
|
||||
{ url: '/logs_view', res_body_length: 2},
|
||||
{ url: '/logs_view', res_body_length: 0},
|
||||
{ url: '/log_view', res_body_length: 2},
|
||||
//{ url: '/stats_view', res_body_length: 1},
|
||||
{ url: '/vessels_view', res_body_length: 1},
|
||||
@@ -198,7 +198,7 @@ const fs = require('fs');
|
||||
user_views: [
|
||||
// not processed yet, { url: '/stays_view', res_body_length: 1},
|
||||
// not processed yet, { url: '/moorages_view', res_body_length: 1},
|
||||
{ url: '/logs_view', res_body_length: 1},
|
||||
{ url: '/logs_view', res_body_length: 0},
|
||||
{ url: '/log_view', res_body_length: 1},
|
||||
//{ url: '/stats_view', res_body_length: 1},
|
||||
{ url: '/vessels_view', res_body_length: 1},
|
||||
|
@@ -47,7 +47,7 @@ const metrics_simulator = require('./metrics_sample_simulator.json');
|
||||
user_views: [
|
||||
// not processed yet, { url: '/stays_view', res_body_length: 1},
|
||||
// not processed yet, { url: '/moorages_view', res_body_length: 1},
|
||||
{ url: '/logs_view', res_body_length: 2},
|
||||
{ url: '/logs_view', res_body_length: 1},
|
||||
{ url: '/log_view', res_body_length: 2},
|
||||
//{ url: '/stats_view', res_body_length: 1},
|
||||
{ url: '/vessels_view', res_body_length: 1},
|
||||
@@ -211,7 +211,7 @@ request.set('User-Agent', 'PostgSail unit tests');
|
||||
res.header['content-type'].should.match(new RegExp('json','g'));
|
||||
res.header['server'].should.match(new RegExp('postgrest','g'));
|
||||
should.exist(res.body.token);
|
||||
res.body.token.should.match(user_jwt);
|
||||
//res.body.token.should.match(user_jwt);
|
||||
console.log(user_jwt);
|
||||
should.exist(user_jwt);
|
||||
done(err);
|
||||
|
@@ -43,7 +43,7 @@ var moment = require('moment');
|
||||
},
|
||||
user_tables: [
|
||||
{ url: '/stays', res_body_length: 3},
|
||||
{ url: '/moorages', res_body_length: 2},
|
||||
{ url: '/moorages', res_body_length: 3},
|
||||
{ url: '/logbook', res_body_length: 2},
|
||||
{ url: '/metadata', res_body_length: 1}
|
||||
],
|
||||
@@ -241,7 +241,7 @@ var moment = require('moment');
|
||||
},
|
||||
user_tables: [
|
||||
{ url: '/stays', res_body_length: 3},
|
||||
{ url: '/moorages', res_body_length: 2},
|
||||
{ url: '/moorages', res_body_length: 4},
|
||||
{ url: '/logbook', res_body_length: 2},
|
||||
{ url: '/metadata', res_body_length: 1}
|
||||
],
|
||||
@@ -684,7 +684,7 @@ request.set('User-Agent', 'PostgSail unit tests');
|
||||
.set('Authorization', `Bearer ${user_jwt}`)
|
||||
.set('Accept', 'application/json')
|
||||
.end(function(err,res){
|
||||
//console.log(res.body);
|
||||
console.log(res.body);
|
||||
res.status.should.equal(200);
|
||||
should.exist(res.header['content-type']);
|
||||
should.exist(res.header['server']);
|
||||
|
196
tests/index4.js
196
tests/index4.js
@@ -3,7 +3,7 @@
|
||||
* Unit test #4
|
||||
* OTP for email, Pushover, Telegram
|
||||
*
|
||||
* process.env.PGSAIL_API_URI = from inside the docker
|
||||
* process.env.PGSAIL_API_URI = from inside the docker
|
||||
*
|
||||
* npm install supertest should mocha mochawesome moment
|
||||
* alias mocha="./node_modules/mocha/bin/_mocha"
|
||||
@@ -154,6 +154,16 @@ var moment = require("moment");
|
||||
payload: null,
|
||||
res: {},
|
||||
},
|
||||
public: [
|
||||
{
|
||||
url: "/rpc/update_user_preferences_fn",
|
||||
payload: { key: "{public_logs}", value: true },
|
||||
},
|
||||
{
|
||||
url: "/rpc/update_user_preferences_fn",
|
||||
payload: { key: "{public_monitoring}", value: true },
|
||||
},
|
||||
],
|
||||
},
|
||||
{
|
||||
cname: process.env.PGSAIL_API_URI,
|
||||
@@ -285,6 +295,16 @@ var moment = require("moment");
|
||||
payload: null,
|
||||
res: {},
|
||||
},
|
||||
public: [
|
||||
{
|
||||
url: "/rpc/update_user_preferences_fn",
|
||||
payload: { key: "{public_logs}", value: true },
|
||||
},
|
||||
{
|
||||
url: "/rpc/update_user_preferences_fn",
|
||||
payload: { key: "{public_monitoring}", value: true },
|
||||
},
|
||||
],
|
||||
},
|
||||
].forEach(function (test) {
|
||||
//console.log(`${test.cname}`);
|
||||
@@ -581,91 +601,127 @@ var moment = require("moment");
|
||||
}); // Function endpoint
|
||||
*/
|
||||
|
||||
describe("Badges, user jwt", function () {
|
||||
it("/rpc/settings_fn return user settings", function (done) {
|
||||
// Reset agent so we do not save cookies
|
||||
request = supertest.agent(test.cname);
|
||||
request
|
||||
.post("/rpc/settings_fn")
|
||||
.set("Authorization", `Bearer ${user_jwt}`)
|
||||
.set("Accept", "application/json")
|
||||
.end(function (err, res) {
|
||||
res.status.should.equal(200);
|
||||
should.exist(res.header["content-type"]);
|
||||
should.exist(res.header["server"]);
|
||||
res.header["content-type"].should.match(new RegExp("json", "g"));
|
||||
res.header["server"].should.match(new RegExp("postgrest", "g"));
|
||||
console.log(res.body);
|
||||
should.exist(res.body.settings);
|
||||
should.exist(res.body.settings.preferences.badges)
|
||||
let badges = res.body.settings.preferences.badges;
|
||||
//console.log(Object.keys(badges));
|
||||
Object.keys(badges).length.should.be.aboveOrEqual(3);
|
||||
(badges).should.have.properties('Helmsman', 'Wake Maker', 'Stormtrooper');
|
||||
done(err);
|
||||
});
|
||||
});
|
||||
}); // user JWT
|
||||
|
||||
describe("Function monitoring endpoint, JWT user_role", function () {
|
||||
let otp = null;
|
||||
test.monitoring.forEach(function (subtest) {
|
||||
it(`${subtest.url}`, function (done) {
|
||||
try {
|
||||
describe("Badges, user jwt", function () {
|
||||
it("/rpc/settings_fn return user settings", function (done) {
|
||||
// Reset agent so we do not save cookies
|
||||
request = supertest.agent(test.cname);
|
||||
request
|
||||
.get(subtest.url)
|
||||
.post("/rpc/settings_fn")
|
||||
.set("Authorization", `Bearer ${user_jwt}`)
|
||||
.set("Accept", "application/json")
|
||||
.end(function (err, res) {
|
||||
res.status.should.equal(200);
|
||||
should.exist(res.header["content-type"]);
|
||||
should.exist(res.header["server"]);
|
||||
res.header["content-type"].should.match(
|
||||
new RegExp("json", "g")
|
||||
res.header["content-type"].should.match(new RegExp("json", "g"));
|
||||
res.header["server"].should.match(new RegExp("postgrest", "g"));
|
||||
console.log(res.body);
|
||||
should.exist(res.body.settings);
|
||||
should.exist(res.body.settings.preferences.badges);
|
||||
let badges = res.body.settings.preferences.badges;
|
||||
//console.log(Object.keys(badges));
|
||||
Object.keys(badges).length.should.be.aboveOrEqual(3);
|
||||
badges.should.have.properties(
|
||||
"Helmsman",
|
||||
"Wake Maker",
|
||||
"Stormtrooper"
|
||||
);
|
||||
done(err);
|
||||
});
|
||||
});
|
||||
}); // user JWT
|
||||
|
||||
describe("Function monitoring endpoint, JWT user_role", function () {
|
||||
let otp = null;
|
||||
test.monitoring.forEach(function (subtest) {
|
||||
it(`${subtest.url}`, function (done) {
|
||||
try {
|
||||
// Reset agent so we do not save cookies
|
||||
request = supertest.agent(test.cname);
|
||||
request
|
||||
.get(subtest.url)
|
||||
.set("Authorization", `Bearer ${user_jwt}`)
|
||||
.set("Accept", "application/json")
|
||||
.end(function (err, res) {
|
||||
res.status.should.equal(200);
|
||||
should.exist(res.header["content-type"]);
|
||||
should.exist(res.header["server"]);
|
||||
res.header["content-type"].should.match(
|
||||
new RegExp("json", "g")
|
||||
);
|
||||
res.header["server"].should.match(new RegExp("postgrest", "g"));
|
||||
//console.log(res.body);
|
||||
should.exist(res.body);
|
||||
//let monitoring = res.body;
|
||||
//console.log(monitoring);
|
||||
// minimum set for static monitoring page
|
||||
// no value for humidity monitoring
|
||||
//monitoring.length.should.be.aboveOrEqual(21);
|
||||
done(err);
|
||||
});
|
||||
} catch (error) {
|
||||
done();
|
||||
}
|
||||
});
|
||||
});
|
||||
}); // Monitoring endpoint
|
||||
|
||||
describe("Event Logs, user jwt", function () {
|
||||
it("/eventlogs_view endpoint, list process_queue, JWT user_role", function (done) {
|
||||
// Reset agent so we do not save cookies
|
||||
request = supertest.agent(test.cname);
|
||||
request
|
||||
.get("/eventlogs_view")
|
||||
.set("Authorization", `Bearer ${user_jwt}`)
|
||||
.set("Accept", "application/json")
|
||||
.end(function (err, res) {
|
||||
res.status.should.equal(200);
|
||||
should.exist(res.header["content-type"]);
|
||||
should.exist(res.header["server"]);
|
||||
res.header["content-type"].should.match(new RegExp("json", "g"));
|
||||
res.header["server"].should.match(new RegExp("postgrest", "g"));
|
||||
//console.log(res.body);
|
||||
should.exist(res.body);
|
||||
//let monitoring = res.body;
|
||||
//console.log(monitoring);
|
||||
// minimum set for static monitoring page
|
||||
// no value for humidity monitoring
|
||||
//monitoring.length.should.be.aboveOrEqual(21);
|
||||
let event = res.body;
|
||||
//console.log(event);
|
||||
// minimum events log for kapla & aava 13 + 4 email_otp = 17
|
||||
event.length.should.be.aboveOrEqual(13);
|
||||
done(err);
|
||||
});
|
||||
} catch (error) {
|
||||
done();
|
||||
}
|
||||
});
|
||||
});
|
||||
}); // Monitoring endpoint
|
||||
|
||||
describe("Event Logs, user jwt", function () {
|
||||
it("/eventlogs_view endpoint, list process_queue, JWT user_role", function (done) {
|
||||
// Reset agent so we do not save cookies
|
||||
request = supertest.agent(test.cname);
|
||||
request
|
||||
.get("/eventlogs_view")
|
||||
.set("Authorization", `Bearer ${user_jwt}`)
|
||||
.set("Accept", "application/json")
|
||||
.end(function (err, res) {
|
||||
res.status.should.equal(200);
|
||||
should.exist(res.header["content-type"]);
|
||||
should.exist(res.header["server"]);
|
||||
res.header["content-type"].should.match(new RegExp("json", "g"));
|
||||
res.header["server"].should.match(new RegExp("postgrest", "g"));
|
||||
//console.log(res.body);
|
||||
should.exist(res.body);
|
||||
let event = res.body;
|
||||
//console.log(event);
|
||||
// minimum events log for kapla & aava 13 + 4 email_otp = 17
|
||||
event.length.should.be.aboveOrEqual(13);
|
||||
done(err);
|
||||
});
|
||||
});
|
||||
}); // user JWT
|
||||
}); // user JWT
|
||||
|
||||
describe("Function update preference for public access endpoint, JWT user_role", function () {
|
||||
test.public.forEach(function (subtest) {
|
||||
it(`${subtest.url}`, function (done) {
|
||||
try {
|
||||
// Reset agent so we do not save cookies
|
||||
request = supertest.agent(test.cname);
|
||||
request
|
||||
.post(subtest.url)
|
||||
.send(subtest.payload)
|
||||
.set("Authorization", `Bearer ${user_jwt}`)
|
||||
.set("Accept", "application/json")
|
||||
.end(function (err, res) {
|
||||
res.status.should.equal(200);
|
||||
should.exist(res.header["content-type"]);
|
||||
should.exist(res.header["server"]);
|
||||
res.header["server"].should.match(new RegExp("postgrest", "g"));
|
||||
//console.log(res.body);
|
||||
should.exist(res.body);
|
||||
//let monitoring = res.body;
|
||||
//console.log(monitoring);
|
||||
// minimum set for static monitoring page
|
||||
// no value for humidity monitoring
|
||||
//monitoring.length.should.be.aboveOrEqual(21);
|
||||
done(err);
|
||||
});
|
||||
} catch (error) {
|
||||
done();
|
||||
}
|
||||
});
|
||||
});
|
||||
}); // Monitoring endpoint
|
||||
|
||||
}); // OpenAPI description
|
||||
}); // Users Array
|
||||
|
187
tests/index5.js
Normal file
187
tests/index5.js
Normal file
@@ -0,0 +1,187 @@
|
||||
"use strict";
|
||||
/*
|
||||
* Unit test #5
|
||||
* Public/Anonymous access
|
||||
*
|
||||
* process.env.PGSAIL_API_URI = from inside the docker
|
||||
*
|
||||
* npm install supertest should mocha mochawesome moment
|
||||
* alias mocha="./node_modules/mocha/bin/_mocha"
|
||||
* mocha index5.js --reporter mochawesome --reporter-options reportDir=/mnt/postgsail/,reportFilename=report_api.html
|
||||
*
|
||||
*/
|
||||
|
||||
const sleep = (ms) => new Promise((r) => setTimeout(r, ms));
|
||||
|
||||
const supertest = require("supertest");
|
||||
// Deprecated
|
||||
const should = require("should");
|
||||
//const chai = require("chai");
|
||||
//const should = chai.should();
|
||||
let request = null;
|
||||
var moment = require("moment");
|
||||
|
||||
// Users Array
|
||||
[
|
||||
{
|
||||
cname: process.env.PGSAIL_API_URI,
|
||||
name: "PostgSail unit test kapla",
|
||||
logs: {
|
||||
url: "/logs_view",
|
||||
header: { name: "x-is-public", value: btoa("kapla,public_logs_list,0") },
|
||||
payload: null,
|
||||
res: {},
|
||||
},
|
||||
log: {
|
||||
url: "/log_view?id=eq.1",
|
||||
header: { name: "x-is-public", value: btoa("kapla,public_logs,1") },
|
||||
payload: null,
|
||||
res: {},
|
||||
},
|
||||
monitoring: {
|
||||
url: "/monitoring_view",
|
||||
header: { name: "x-is-public", value: btoa("kapla,public_monitoring,0") },
|
||||
payload: null,
|
||||
res: {},
|
||||
},
|
||||
timelapse: {
|
||||
url: "/rpc/timelapse_fn",
|
||||
header: { name: "x-is-public", value: btoa("kapla,public_timelapse,1") },
|
||||
payload: null,
|
||||
res: {},
|
||||
},
|
||||
export_gpx: {
|
||||
url: "/rpc/export_logbook_gpx_fn",
|
||||
header: { name: "x-is-public", value: btoa("kapla,public_logs,0") },
|
||||
payload: null,
|
||||
res: {},
|
||||
},
|
||||
},
|
||||
{
|
||||
cname: process.env.PGSAIL_API_URI,
|
||||
name: "PostgSail unit test, aava",
|
||||
logs: {
|
||||
url: "/logs_view",
|
||||
header: { name: "x-is-public", value: btoa("aava,public_logs_list,0") },
|
||||
payload: null,
|
||||
res: {},
|
||||
},
|
||||
log: {
|
||||
url: "/log_view?id=eq.3",
|
||||
header: { name: "x-is-public", value: btoa("aava,public_logs,3") },
|
||||
payload: null,
|
||||
res: {},
|
||||
},
|
||||
monitoring: {
|
||||
url: "/monitoring_view",
|
||||
header: { name: "x-is-public", value: btoa("aava,public_monitoring,0") },
|
||||
payload: null,
|
||||
res: {},
|
||||
},
|
||||
timelapse: {
|
||||
url: "/rpc/timelapse_fn",
|
||||
header: { name: "x-is-public", value: btoa("aava,public_timelapse,0") },
|
||||
payload: null,
|
||||
res: {},
|
||||
},
|
||||
export_gpx: {
|
||||
url: "/rpc/export_logbook_gpx_fn",
|
||||
header: { name: "x-is-public", value: btoa("aava,public_logs,0") },
|
||||
payload: null,
|
||||
res: {},
|
||||
},
|
||||
},
|
||||
].forEach(function (test) {
|
||||
//console.log(`${test.cname}`);
|
||||
describe(`${test.name}`, function () {
|
||||
request = supertest.agent(test.cname);
|
||||
request.set("User-Agent", "PostgSail unit tests");
|
||||
|
||||
describe("Get JWT api_anonymous", function () {
|
||||
it("/logs_view, api_anonymous no jwt token", function (done) {
|
||||
// Reset agent so we do not save cookies
|
||||
request = supertest.agent(test.cname);
|
||||
request
|
||||
.get(test.logs.url)
|
||||
.set(test.logs.header.name, test.logs.header.value)
|
||||
.set("Accept", "application/json")
|
||||
.end(function (err, res) {
|
||||
res.status.should.equal(404);
|
||||
should.exist(res.header["content-type"]);
|
||||
should.exist(res.header["server"]);
|
||||
res.header["content-type"].should.match(new RegExp("json", "g"));
|
||||
res.header["server"].should.match(new RegExp("postgrest", "g"));
|
||||
done(err);
|
||||
});
|
||||
});
|
||||
it("/log_view, api_anonymous no jwt token", function (done) {
|
||||
// Reset agent so we do not save cookies
|
||||
request = supertest.agent(test.cname);
|
||||
request
|
||||
.get(test.log.url)
|
||||
.set(test.log.header.name, test.log.header.value)
|
||||
.set("Accept", "application/json")
|
||||
.end(function (err, res) {
|
||||
res.status.should.equal(200);
|
||||
should.exist(res.header["content-type"]);
|
||||
should.exist(res.header["server"]);
|
||||
res.header["content-type"].should.match(new RegExp("json", "g"));
|
||||
res.header["server"].should.match(new RegExp("postgrest", "g"));
|
||||
done(err);
|
||||
});
|
||||
});
|
||||
it("/monitoring_view, api_anonymous no jwt token", function (done) {
|
||||
// Reset agent so we do not save cookies
|
||||
request = supertest.agent(test.cname);
|
||||
request
|
||||
.get(test.monitoring.url)
|
||||
.set(test.monitoring.header.name, test.monitoring.header.value)
|
||||
.set("Accept", "application/json")
|
||||
.end(function (err, res) {
|
||||
console.log(res.text);
|
||||
res.status.should.equal(200);
|
||||
should.exist(res.header["content-type"]);
|
||||
should.exist(res.header["server"]);
|
||||
res.header["content-type"].should.match(new RegExp("json", "g"));
|
||||
res.header["server"].should.match(new RegExp("postgrest", "g"));
|
||||
done(err);
|
||||
});
|
||||
});
|
||||
it("/rpc/timelapse_fn, api_anonymous no jwt token", function (done) {
|
||||
// Reset agent so we do not save cookies
|
||||
request = supertest.agent(test.cname);
|
||||
request
|
||||
.post(test.timelapse.url)
|
||||
.set(test.timelapse.header.name, test.timelapse.header.value)
|
||||
.set("Accept", "application/json")
|
||||
.end(function (err, res) {
|
||||
console.log(res.text);
|
||||
res.status.should.equal(404);
|
||||
should.exist(res.header["content-type"]);
|
||||
should.exist(res.header["server"]);
|
||||
res.header["content-type"].should.match(new RegExp("json", "g"));
|
||||
res.header["server"].should.match(new RegExp("postgrest", "g"));
|
||||
done(err);
|
||||
});
|
||||
});
|
||||
it("/rpc/export_logbook_gpx_fn, api_anonymous no jwt token", function (done) {
|
||||
// Reset agent so we do not save cookies
|
||||
request = supertest.agent(test.cname);
|
||||
request
|
||||
.post(test.export_gpx.url)
|
||||
.send({_id: 1})
|
||||
.set(test.export_gpx.header.name, test.export_gpx.header.value)
|
||||
.set("Accept", "application/json")
|
||||
.end(function (err, res) {
|
||||
console.log(res.text)
|
||||
res.status.should.equal(401);
|
||||
should.exist(res.header["content-type"]);
|
||||
should.exist(res.header["server"]);
|
||||
res.header["content-type"].should.match(new RegExp("json", "g"));
|
||||
res.header["server"].should.match(new RegExp("postgrest", "g"));
|
||||
done(err);
|
||||
});
|
||||
});
|
||||
}); // user JWT
|
||||
}); // OpenAPI description
|
||||
}); // Users Array
|
@@ -21,7 +21,19 @@
|
||||
"courseovergroundtrue" : 197.4,
|
||||
"windspeedapparent" : 15.4,
|
||||
"anglespeedapparent" : 43.0,
|
||||
"status" : "moored",
|
||||
"status" : "sailing",
|
||||
"metrics" : {"navigation.log": 17441395, "navigation.trip.log": 80284, "navigation.headingTrue": 3.4924, "navigation.gnss.satellites": 11, "environment.depth.belowKeel": 32.289, "navigation.magneticVariation": 0.1414, "navigation.speedThroughWater": 3.34, "environment.water.temperature": 313.15, "electrical.batteries.1.current": 231, "electrical.batteries.1.voltage": 14.45, "navigation.gnss.antennaAltitude": -0.04, "network.n2k.ngt-1.130356.errorID": 0, "network.n2k.ngt-1.130356.modelID": 14, "environment.depth.belowTransducer": 32.29, "electrical.batteries.1.temperature": 299.82, "environment.depth.transducerToKeel": -0.001, "navigation.gnss.horizontalDilution": 0.8, "network.n2k.ngt-1.130356.ch1.rxLoad": 4, "network.n2k.ngt-1.130356.ch1.txLoad": 0, "network.n2k.ngt-1.130356.ch2.rxLoad": 0, "network.n2k.ngt-1.130356.ch2.txLoad": 57, "network.n2k.ngt-1.130356.ch1.deleted": 0, "network.n2k.ngt-1.130356.ch2.deleted": 0, "network.n2k.ngt-1.130356.ch2Bandwidth": 4, "network.n2k.ngt-1.130356.ch1.bandwidth": 3, "network.n2k.ngt-1.130356.ch1.rxDropped": 0, "network.n2k.ngt-1.130356.ch2.rxDropped": 0, "network.n2k.ngt-1.130356.ch1.rxFiltered": 0, "network.n2k.ngt-1.130356.ch2.rxFiltered": 0, "network.n2k.ngt-1.130356.ch1.rxBandwidth": 5, "network.n2k.ngt-1.130356.ch1.txBandwidth": 0, "network.n2k.ngt-1.130356.ch2.rxBandwidth": 0, "network.n2k.ngt-1.130356.ch2.txBandwidth": 11, "network.n2k.ngt-1.130356.uniChannelCount": 2, "network.n2k.ngt-1.130356.indiChannelCount": 2, "network.n2k.ngt-1.130356.ch1.BufferLoading": 0, "network.n2k.ngt-1.130356.ch2.bufferLoading": 0, "network.n2k.ngt-1.130356.ch1.PointerLoading": 0, "network.n2k.ngt-1.130356.ch2.pointerLoading": 0}
|
||||
},
|
||||
{
|
||||
"time" : "2022-07-31T11:29:13.340Z",
|
||||
"client_id" : "vessels.urn:mrn:imo:mmsi:987654321",
|
||||
"latitude" : 59.7213961,
|
||||
"longitude" : 24.7349507,
|
||||
"speedoverground" : 6.5,
|
||||
"courseovergroundtrue" : 197.4,
|
||||
"windspeedapparent" : 15.4,
|
||||
"anglespeedapparent" : 43.0,
|
||||
"status" : "sailing",
|
||||
"metrics" : {"navigation.log": 17441395, "navigation.trip.log": 80284, "navigation.headingTrue": 3.4924, "navigation.gnss.satellites": 11, "environment.depth.belowKeel": 32.289, "navigation.magneticVariation": 0.1414, "navigation.speedThroughWater": 3.34, "environment.water.temperature": 313.15, "electrical.batteries.1.current": 231, "electrical.batteries.1.voltage": 14.45, "navigation.gnss.antennaAltitude": -0.04, "network.n2k.ngt-1.130356.errorID": 0, "network.n2k.ngt-1.130356.modelID": 14, "environment.depth.belowTransducer": 32.29, "electrical.batteries.1.temperature": 299.82, "environment.depth.transducerToKeel": -0.001, "navigation.gnss.horizontalDilution": 0.8, "network.n2k.ngt-1.130356.ch1.rxLoad": 4, "network.n2k.ngt-1.130356.ch1.txLoad": 0, "network.n2k.ngt-1.130356.ch2.rxLoad": 0, "network.n2k.ngt-1.130356.ch2.txLoad": 57, "network.n2k.ngt-1.130356.ch1.deleted": 0, "network.n2k.ngt-1.130356.ch2.deleted": 0, "network.n2k.ngt-1.130356.ch2Bandwidth": 4, "network.n2k.ngt-1.130356.ch1.bandwidth": 3, "network.n2k.ngt-1.130356.ch1.rxDropped": 0, "network.n2k.ngt-1.130356.ch2.rxDropped": 0, "network.n2k.ngt-1.130356.ch1.rxFiltered": 0, "network.n2k.ngt-1.130356.ch2.rxFiltered": 0, "network.n2k.ngt-1.130356.ch1.rxBandwidth": 5, "network.n2k.ngt-1.130356.ch1.txBandwidth": 0, "network.n2k.ngt-1.130356.ch2.rxBandwidth": 0, "network.n2k.ngt-1.130356.ch2.txBandwidth": 11, "network.n2k.ngt-1.130356.uniChannelCount": 2, "network.n2k.ngt-1.130356.indiChannelCount": 2, "network.n2k.ngt-1.130356.ch1.BufferLoading": 0, "network.n2k.ngt-1.130356.ch2.bufferLoading": 0, "network.n2k.ngt-1.130356.ch1.PointerLoading": 0, "network.n2k.ngt-1.130356.ch2.pointerLoading": 0}
|
||||
},
|
||||
{
|
||||
|
@@ -12,6 +12,18 @@
|
||||
"status" : "moored",
|
||||
"metrics" : {"environment.wind.speedTrue": 4.44, "navigation.speedThroughWater": 3.0918118943701245, "performance.velocityMadeGood": 2.9323340761912995, "environment.wind.angleTrueWater": -0.3665191430024964, "environment.depth.belowTransducer": 13.1, "navigation.courseOverGroundMagnetic": 3.620685534088946, "navigation.courseRhumbline.crossTrackError": 0}
|
||||
},
|
||||
{
|
||||
"time" : "2022-07-30T14:52:28.000Z",
|
||||
"client_id" : "vessels.urn:mrn:imo:mmsi:123456789",
|
||||
"latitude" : 60.077666666666666,
|
||||
"longitude" : 23.530866666666668,
|
||||
"speedoverground" : 0.0,
|
||||
"courseovergroundtrue" : 207.5,
|
||||
"windspeedapparent" : 14.8,
|
||||
"anglespeedapparent" : -12.0,
|
||||
"status" : "sailing",
|
||||
"metrics" : {"environment.wind.speedTrue": 4.44, "navigation.speedThroughWater": 3.0918118943701245, "performance.velocityMadeGood": 2.9323340761912995, "environment.wind.angleTrueWater": -0.3665191430024964, "environment.depth.belowTransducer": 13.1, "navigation.courseOverGroundMagnetic": 3.620685534088946, "navigation.courseRhumbline.crossTrackError": 0, "propulsion.main.runTime":1776241 }
|
||||
},
|
||||
{
|
||||
"time" : "2022-07-30T14:53:28.000Z",
|
||||
"client_id" : "vessels.urn:mrn:imo:mmsi:123456789",
|
||||
@@ -21,8 +33,8 @@
|
||||
"courseovergroundtrue" : 207.5,
|
||||
"windspeedapparent" : 14.8,
|
||||
"anglespeedapparent" : -12.0,
|
||||
"status" : "moored",
|
||||
"metrics" : {"environment.wind.speedTrue": 4.44, "navigation.speedThroughWater": 3.0918118943701245, "performance.velocityMadeGood": 2.9323340761912995, "environment.wind.angleTrueWater": -0.3665191430024964, "environment.depth.belowTransducer": 13.1, "navigation.courseOverGroundMagnetic": 3.620685534088946, "navigation.courseRhumbline.crossTrackError": 0, "propulsion.main.runTime":1776241 }
|
||||
"status" : "sailing",
|
||||
"metrics" : {"environment.wind.speedTrue": 4.44, "navigation.speedThroughWater": 3.0918118943701245, "performance.velocityMadeGood": 2.9323340761912995, "environment.wind.angleTrueWater": -0.3665191430024964, "environment.depth.belowTransducer": 13.1, "navigation.courseOverGroundMagnetic": 3.620685534088946, "navigation.courseRhumbline.crossTrackError": 0 }
|
||||
},
|
||||
{
|
||||
"time" : "2022-07-30T14:54:28.016Z",
|
||||
@@ -322,7 +334,7 @@
|
||||
"windspeedapparent" : 11.1,
|
||||
"anglespeedapparent" : 88.0,
|
||||
"status" : "sailing",
|
||||
"metrics" : {"environment.wind.speedTrue": 3.1895563635765014, "navigation.speedThroughWater": 0, "performance.velocityMadeGood": 0, "environment.wind.angleTrueWater": 1.8151424224885533, "environment.depth.belowTransducer": 1.67, "navigation.courseOverGroundMagnetic": 3.1290262836898832, "navigation.courseRhumbline.crossTrackError": 0}
|
||||
"metrics" : {"environment.wind.speedTrue": 3.1895563635765014, "navigation.speedThroughWater": 0, "performance.velocityMadeGood": 0, "environment.wind.angleTrueWater": 1.8151424224885533, "environment.depth.belowTransducer": 1.67, "navigation.courseOverGroundMagnetic": 3.1290262836898832, "navigation.courseRhumbline.crossTrackError": 0 }
|
||||
},
|
||||
{
|
||||
"time" : "2022-07-30T15:19:28.467Z",
|
||||
@@ -348,6 +360,18 @@
|
||||
"status" : "moored",
|
||||
"metrics" : {"environment.wind.speedTrue": 0, "navigation.speedThroughWater": 0, "performance.velocityMadeGood": 0, "environment.wind.angleTrueWater": 0.7853981635767779, "environment.depth.belowTransducer": 1.65, "navigation.courseOverGroundMagnetic": 4.206068965341505, "navigation.courseRhumbline.crossTrackError": 0}
|
||||
},
|
||||
{
|
||||
"time" : "2022-07-30T15:20:28.467Z",
|
||||
"client_id" : "vessels.urn:mrn:imo:mmsi:123456789",
|
||||
"latitude" : 59.97688333333333,
|
||||
"longitude" : 23.4321,
|
||||
"speedoverground" : 0.0,
|
||||
"courseovergroundtrue" : 241.0,
|
||||
"windspeedapparent" : 4.3,
|
||||
"anglespeedapparent" : 74.0,
|
||||
"status" : "sailing",
|
||||
"metrics" : {"environment.wind.speedTrue": 0, "navigation.speedThroughWater": 0, "performance.velocityMadeGood": 0, "environment.wind.angleTrueWater": 0.7853981635767779, "environment.depth.belowTransducer": 1.65, "navigation.courseOverGroundMagnetic": 4.206068965341505, "navigation.courseRhumbline.crossTrackError": 0, "propulsion.main.runTime":1776251}
|
||||
},
|
||||
{
|
||||
"time" : "2022-07-30T15:21:28.467Z",
|
||||
"client_id" : "vessels.urn:mrn:imo:mmsi:123456789",
|
||||
@@ -357,7 +381,7 @@
|
||||
"courseovergroundtrue" : 241.0,
|
||||
"windspeedapparent" : 4.3,
|
||||
"anglespeedapparent" : 74.0,
|
||||
"status" : "moored",
|
||||
"status" : "sailing",
|
||||
"metrics" : {"environment.wind.speedTrue": 0, "navigation.speedThroughWater": 0, "performance.velocityMadeGood": 0, "environment.wind.angleTrueWater": 0.7853981635767779, "environment.depth.belowTransducer": 1.65, "navigation.courseOverGroundMagnetic": 4.206068965341505, "navigation.courseRhumbline.crossTrackError": 0}
|
||||
},
|
||||
{
|
||||
|
20
tests/sql/anonymous.sql
Normal file
20
tests/sql/anonymous.sql
Normal file
@@ -0,0 +1,20 @@
|
||||
---------------------------------------------------------------------------
|
||||
-- Listing
|
||||
--
|
||||
|
||||
-- List current database
|
||||
select current_database();
|
||||
|
||||
-- connect to the DB
|
||||
\c signalk
|
||||
|
||||
-- output display format
|
||||
\x on
|
||||
|
||||
\echo 'Validate anonymous access'
|
||||
SELECT api.ispublic_fn('kapla', 'public_test');
|
||||
SELECT api.ispublic_fn('kapla', 'public_logs_list');
|
||||
SELECT api.ispublic_fn('kapla', 'public_logs', 1);
|
||||
SELECT api.ispublic_fn('kapla', 'public_logs', 3);
|
||||
SELECT api.ispublic_fn('kapla', 'public_monitoring');
|
||||
SELECT api.ispublic_fn('kapla', 'public_timelapse');
|
23
tests/sql/anonymous.sql.output
Normal file
23
tests/sql/anonymous.sql.output
Normal file
@@ -0,0 +1,23 @@
|
||||
current_database
|
||||
------------------
|
||||
signalk
|
||||
(1 row)
|
||||
|
||||
You are now connected to database "signalk" as user "username".
|
||||
Expanded display is on.
|
||||
Validate anonymous access
|
||||
-[ RECORD 1 ]--
|
||||
ispublic_fn | f
|
||||
|
||||
-[ RECORD 1 ]--
|
||||
ispublic_fn | f
|
||||
|
||||
-[ RECORD 1 ]--
|
||||
ispublic_fn | t
|
||||
|
||||
-[ RECORD 1 ]--
|
||||
ispublic_fn | t
|
||||
|
||||
-[ RECORD 1 ]--
|
||||
ispublic_fn | f
|
||||
|
@@ -18,7 +18,7 @@ SELECT set_config('vessel.id', :'vessel_id', false) IS NOT NULL as vessel_id;
|
||||
\echo 'Insert new api.logbook for badges'
|
||||
INSERT INTO api.logbook
|
||||
(id, active, "name", "_from", "_from_lat", "_from_lng", "_to", "_to_lat", "_to_lng", track_geom, track_geog, track_geojson, "_from_time", "_to_time", distance, duration, avg_speed, max_speed, max_wind_speed, notes, vessel_id)
|
||||
VALUES
|
||||
OVERRIDING SYSTEM VALUE VALUES
|
||||
(nextval('api.logbook_id_seq'), false, 'Tropics Zone', NULL, NULL, NULL, NULL, NULL, NULL, 'SRID=4326;LINESTRING (-63.151124640791096 14.01074681627324, -77.0912026418618 12.870995731013664)'::public.geometry, NULL, NULL, NOW(), NOW(), 123, NULL, NULL, NULL, NULL, NULL, current_setting('vessel.id', false)),
|
||||
(nextval('api.logbook_id_seq'), false, 'Alaska Zone', NULL, NULL, NULL, NULL, NULL, NULL, 'SRID=4326;LINESTRING (-143.5773697471158 59.4404631255976, -152.35402122385003 56.58243132943173)'::public.geometry, NULL, NULL, NOW(), NOW(), 1234, NULL, NULL, NULL, NULL, NULL, current_setting('vessel.id', false));
|
||||
|
||||
@@ -53,10 +53,10 @@ SELECT
|
||||
|
||||
\echo 'Insert new api.moorages for badges'
|
||||
INSERT INTO api.moorages
|
||||
(id,"name",country,stay_id,stay_code,stay_duration,reference_count,latitude,longitude,geog,home_flag,notes,vessel_id)
|
||||
VALUES
|
||||
(5,'Badge Mooring Pro',NULL,5,3,'11 days 00:39:56.418',1,NULL,NULL,NULL,false,'Badge Mooring Pro',current_setting('vessel.id', false)),
|
||||
(6,'Badge Anchormaster',NULL,5,2,'26 days 00:49:56.418',1,NULL,NULL,NULL,false,'Badge Anchormaster',current_setting('vessel.id', false));
|
||||
(id,"name",country,stay_code,stay_duration,reference_count,latitude,longitude,geog,home_flag,notes,vessel_id)
|
||||
OVERRIDING SYSTEM VALUE VALUES
|
||||
(8,'Badge Mooring Pro',NULL,3,'11 days 00:39:56.418',1,NULL,NULL,NULL,false,'Badge Mooring Pro',current_setting('vessel.id', false)),
|
||||
(9,'Badge Anchormaster',NULL,2,'26 days 00:49:56.418',1,NULL,NULL,NULL,false,'Badge Anchormaster',current_setting('vessel.id', false));
|
||||
|
||||
\echo 'Set config'
|
||||
SELECT set_config('user.email', 'demo+aava@openplotter.cloud', false);
|
||||
|
@@ -16,28 +16,28 @@ logbook
|
||||
count | 2
|
||||
|
||||
logbook
|
||||
-[ RECORD 1 ]--+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
name | Bollsta to Slottsbacken
|
||||
-[ RECORD 1 ]--+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
name | Pojoviken to Norra hamnen
|
||||
_from_time | t
|
||||
_to_time | t
|
||||
track_geojson | t
|
||||
track_geom | 0102000020E61000001A00000020D26F5F0786374030BB270F0B094E400C6E7ED60F843740AA60545227084E40D60FC48C03823740593CE27D42074E407B39D9F322803740984C158C4A064E4091ED7C3F357E3740898BB63D54054E40A8A1208B477C37404BA3DC9059044E404C5CB4EDA17A3740C4F856115B034E40A9A44E4013793740D8F0F44A59024E40E4839ECDAA773740211FF46C56014E405408D147067637408229F03B73004E40787AA52C43743740F90FE9B7AFFF4D40F8098D4D18723740C217265305FF4D4084E82303537037409A2D464AA0FE4D4022474DCE636F37402912396A72FE4D408351499D806E374088CFB02B40FE4D4076711B0DE06D3740B356C7040FFE4D404EAC66B0BC6E374058A835CD3BFE4D40D7A3703D0A6F3740D3E10EC15EFE4D4087602F277B6E3740A779C7293AFE4D4087602F277B6E3740A779C7293AFE4D402063EE5A426E3740B5A679C729FE4D40381DEE10EC6D37409ECA7C1A0AFE4D40E2C46A06CB6B37400A43F7BF36FD4D4075931804566E3740320BDAD125FD4D409A2D464AA06E37404A5658830AFD4D40029A081B9E6E37404A5658830AFD4D40
|
||||
distance | 7.17
|
||||
duration | PT25M
|
||||
avg_speed | 3.6961538461538455
|
||||
track_geom | 0102000020E61000001C000000B0DEBBE0E68737404DA938FBF0094E40B0DEBBE0E68737404DA938FBF0094E4020D26F5F0786374030BB270F0B094E400C6E7ED60F843740AA60545227084E40D60FC48C03823740593CE27D42074E407B39D9F322803740984C158C4A064E4091ED7C3F357E3740898BB63D54054E40A8A1208B477C37404BA3DC9059044E404C5CB4EDA17A3740C4F856115B034E40A9A44E4013793740D8F0F44A59024E40E4839ECDAA773740211FF46C56014E405408D147067637408229F03B73004E40787AA52C43743740F90FE9B7AFFF4D40F8098D4D18723740C217265305FF4D4084E82303537037409A2D464AA0FE4D4022474DCE636F37402912396A72FE4D408351499D806E374088CFB02B40FE4D4076711B0DE06D3740B356C7040FFE4D404EAC66B0BC6E374058A835CD3BFE4D40D7A3703D0A6F3740D3E10EC15EFE4D4087602F277B6E3740A779C7293AFE4D4087602F277B6E3740A779C7293AFE4D402063EE5A426E3740B5A679C729FE4D40381DEE10EC6D37409ECA7C1A0AFE4D40E2C46A06CB6B37400A43F7BF36FD4D4075931804566E3740320BDAD125FD4D409A2D464AA06E37404A5658830AFD4D40029A081B9E6E37404A5658830AFD4D40
|
||||
distance | 7.6447
|
||||
duration | PT27M
|
||||
avg_speed | 3.6357142857142852
|
||||
max_speed | 6.1
|
||||
max_wind_speed | 22.1
|
||||
notes | new log note
|
||||
extra | {"metrics": {"propulsion.main.runTime": 10}, "observations": {"seaState": -1, "visibility": -1, "cloudCoverage": -1}}
|
||||
-[ RECORD 2 ]--+-------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
name | Knipan to Ekenäs
|
||||
-[ RECORD 2 ]--+-----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
name | Norra hamnen to Ekenäs
|
||||
_from_time | t
|
||||
_to_time | t
|
||||
track_geojson | t
|
||||
track_geom | 0102000020E6100000130000004806A6C0EF6C3740DA1B7C6132FD4D40FE65F7E461693740226C787AA5FC4D407DD3E10EC1663740B29DEFA7C6FB4D40898BB63D5465374068479724BCFA4D409A5271F6E1633740B6847CD0B3F94D40431CEBE236623740E9263108ACF84D402C6519E2585F37407E678EBFC7F74D4096218E75715B374027C5B45C23F74D402AA913D044583740968DE1C46AF64D405AF5B9DA8A5537407BEF829B9FF54D407449C2ABD253374086C954C1A8F44D407D1A0AB278543740F2B0506B9AF34D409D11A5BDC15737406688635DDCF24D4061C3D32B655937402CAF6F3ADCF14D408988888888583740B3319C58CDF04D4021FAC8C0145837408C94405DB7EF4D40B8F9593F105B37403DC0804BEDEE4D40DE4C5FE2A25D3740AE47E17A14EE4D40DE4C5FE2A25D3740AE47E17A14EE4D40
|
||||
distance | 8.6862
|
||||
duration | PT18M
|
||||
avg_speed | 6.026315789473684
|
||||
track_geom | 0102000020E610000015000000029A081B9E6E37404A5658830AFD4D40029A081B9E6E37404A5658830AFD4D404806A6C0EF6C3740DA1B7C6132FD4D40FE65F7E461693740226C787AA5FC4D407DD3E10EC1663740B29DEFA7C6FB4D40898BB63D5465374068479724BCFA4D409A5271F6E1633740B6847CD0B3F94D40431CEBE236623740E9263108ACF84D402C6519E2585F37407E678EBFC7F74D4096218E75715B374027C5B45C23F74D402AA913D044583740968DE1C46AF64D405AF5B9DA8A5537407BEF829B9FF54D407449C2ABD253374086C954C1A8F44D407D1A0AB278543740F2B0506B9AF34D409D11A5BDC15737406688635DDCF24D4061C3D32B655937402CAF6F3ADCF14D408988888888583740B3319C58CDF04D4021FAC8C0145837408C94405DB7EF4D40B8F9593F105B37403DC0804BEDEE4D40DE4C5FE2A25D3740AE47E17A14EE4D40DE4C5FE2A25D3740AE47E17A14EE4D40
|
||||
distance | 8.8968
|
||||
duration | PT20M
|
||||
avg_speed | 5.4523809523809526
|
||||
max_speed | 6.5
|
||||
max_wind_speed | 37.2
|
||||
notes |
|
||||
@@ -49,24 +49,24 @@ count | 3
|
||||
|
||||
stays
|
||||
-[ RECORD 1 ]-------------------------------------------------
|
||||
active | f
|
||||
name | Bollsta
|
||||
geog | 0101000020E6100000B0DEBBE0E68737404DA938FBF0094E40
|
||||
active | t
|
||||
name |
|
||||
geog |
|
||||
stay_code | 2
|
||||
-[ RECORD 2 ]-------------------------------------------------
|
||||
active | f
|
||||
name | Slottsbacken
|
||||
geog | 0101000020E6100000029A081B9E6E37404A5658830AFD4D40
|
||||
stay_code | 1
|
||||
-[ RECORD 3 ]-------------------------------------------------
|
||||
active | t
|
||||
name | Ekenäs
|
||||
geog | 0101000020E6100000DE4C5FE2A25D3740AE47E17A14EE4D40
|
||||
name | 0 days stay at Pojoviken in November 2023
|
||||
geog | 0101000020E6100000B0DEBBE0E68737404DA938FBF0094E40
|
||||
stay_code | 2
|
||||
-[ RECORD 3 ]-------------------------------------------------
|
||||
active | f
|
||||
name | 0 days stay at Norra hamnen in November 2023
|
||||
geog | 0101000020E6100000029A081B9E6E37404A5658830AFD4D40
|
||||
stay_code | 4
|
||||
|
||||
eventlogs_view
|
||||
-[ RECORD 1 ]
|
||||
count | 13
|
||||
count | 11
|
||||
|
||||
stats_logs_fn
|
||||
SELECT 1
|
||||
@@ -74,11 +74,11 @@ SELECT 1
|
||||
name | "kapla"
|
||||
count | 4
|
||||
max_speed | 7.1
|
||||
max_distance | 8.6862
|
||||
max_distance | 8.8968
|
||||
max_duration | "PT1H11M"
|
||||
?column? | 3
|
||||
?column? | 29.2865
|
||||
?column? | "PT2H37M"
|
||||
?column? | 30.1154
|
||||
?column? | "PT2H43M"
|
||||
?column? | 44.2
|
||||
?column? | 2
|
||||
?column? | 4
|
||||
|
@@ -6,7 +6,7 @@
|
||||
You are now connected to database "signalk" as user "username".
|
||||
Expanded display is on.
|
||||
-[ RECORD 1 ]
|
||||
jobs | 28
|
||||
jobs | 24
|
||||
|
||||
-[ RECORD 1 ]-+-
|
||||
run_cron_jobs |
|
||||
|
@@ -23,7 +23,7 @@ SELECT current_user, current_setting('user.email', true), current_setting('vesse
|
||||
SELECT v.name,m.client_id FROM auth.accounts a JOIN auth.vessels v ON a.role = 'user_role' AND v.owner_email = a.email JOIN api.metadata m ON m.vessel_id = v.vessel_id;
|
||||
|
||||
\echo 'auth.accounts details'
|
||||
SELECT a.public_id IS NOT NULL AS public_id, a.user_id IS NOT NULL AS user_id, a.email, a.first, a.last, a.pass IS NOT NULL AS pass, a.role, a.preferences->'telegram'->'chat' AS telegram, a.preferences->'pushover_user_key' AS pushover_user_key FROM auth.accounts AS a;
|
||||
SELECT a.user_id IS NOT NULL AS user_id, a.email, a.first, a.last, a.pass IS NOT NULL AS pass, a.role, a.preferences->'telegram'->'chat' AS telegram, a.preferences->'pushover_user_key' AS pushover_user_key FROM auth.accounts AS a;
|
||||
\echo 'auth.vessels details'
|
||||
--SELECT 'SELECT ' || STRING_AGG('v.' || column_name, ', ') || ' FROM auth.vessels AS v' FROM information_schema.columns WHERE table_name = 'vessels' AND table_schema = 'auth' AND column_name NOT IN ('created_at', 'updated_at');
|
||||
SELECT v.vessel_id IS NOT NULL AS vessel_id, v.owner_email, v.mmsi, v.name, v.role FROM auth.vessels AS v;
|
||||
@@ -60,12 +60,12 @@ SELECT m.id, m.name, m.mmsi, m.client_id, m.length, m.beam, m.height, m.ship_typ
|
||||
\echo 'api.logs_view'
|
||||
--SELECT * FROM api.logbook l;
|
||||
--SELECT * FROM api.logs_view l;
|
||||
SELECT l.id, l.name, l.from, l.to, l.distance, l.duration FROM api.logs_view AS l;
|
||||
SELECT l.id, l.name, l.from, l.to, l.distance, l.duration, l._from_moorage_id, l._to_moorage_id FROM api.logs_view AS l;
|
||||
--SELECT * FROM api.log_view l;
|
||||
|
||||
\echo 'api.stays'
|
||||
--SELECT * FROM api.stays s;
|
||||
SELECT m.id, m.vessel_id IS NOT NULL AS vessel_id, m.active, m.name, m.latitude, m.longitude, m.geog, m.arrived IS NOT NULL AS arrived, m.departed IS NOT NULL AS departed, m.duration, m.stay_code, m.notes FROM api.stays AS m;
|
||||
SELECT m.id, m.vessel_id IS NOT NULL AS vessel_id, m.moorage_id, m.active, m.name, m.latitude, m.longitude, m.geog, m.arrived IS NOT NULL AS arrived, m.departed IS NOT NULL AS departed, m.duration, m.stay_code, m.notes FROM api.stays AS m;
|
||||
|
||||
\echo 'stays_view'
|
||||
--SELECT * FROM api.stays_view s;
|
||||
@@ -73,7 +73,7 @@ SELECT m.id, m.name IS NOT NULL AS name, m.moorage, m.moorage_id, m.duration, m.
|
||||
|
||||
\echo 'api.moorages'
|
||||
--SELECT * FROM api.moorages m;
|
||||
SELECT m.id, m.vessel_id IS NOT NULL AS vessel_id, m.name, m.country, m.stay_id, m.stay_code, m.stay_duration, m.reference_count, m.latitude, m.longitude, m.geog, m.home_flag, m.notes FROM api.moorages AS m;
|
||||
SELECT m.id, m.vessel_id IS NOT NULL AS vessel_id, m.name, m.country, m.stay_code, m.stay_duration, m.reference_count, m.latitude, m.longitude, m.geog, m.home_flag, m.notes FROM api.moorages AS m;
|
||||
|
||||
\echo 'api.moorages_view'
|
||||
SELECT * FROM api.moorages_view s;
|
||||
|
@@ -15,29 +15,27 @@ current_setting |
|
||||
|
||||
link vessel and user based on current_setting
|
||||
-[ RECORD 1 ]----------------------------------------------------------------
|
||||
name | kapla
|
||||
client_id | vessels.urn:mrn:signalk:uuid:5b4f7543-7153-4840-b139-761310b242fd
|
||||
-[ RECORD 2 ]----------------------------------------------------------------
|
||||
name | aava
|
||||
client_id | vessels.urn:mrn:imo:mmsi:787654321
|
||||
-[ RECORD 2 ]----------------------------------------------------------------
|
||||
name | kapla
|
||||
client_id | vessels.urn:mrn:signalk:uuid:5b4f7543-7153-4840-b139-761310b242fd
|
||||
|
||||
auth.accounts details
|
||||
-[ RECORD 1 ]-----+-----------------------------
|
||||
public_id | t
|
||||
user_id | t
|
||||
email | demo+kapla@openplotter.cloud
|
||||
first | First_kapla
|
||||
last | Last_kapla
|
||||
email | demo+aava@openplotter.cloud
|
||||
first | first_aava
|
||||
last | last_aava
|
||||
pass | t
|
||||
role | user_role
|
||||
telegram |
|
||||
pushover_user_key |
|
||||
-[ RECORD 2 ]-----+-----------------------------
|
||||
public_id | t
|
||||
user_id | t
|
||||
email | demo+aava@openplotter.cloud
|
||||
first | first_aava
|
||||
last | last_aava
|
||||
email | demo+kapla@openplotter.cloud
|
||||
first | First_kapla
|
||||
last | Last_kapla
|
||||
pass | t
|
||||
role | user_role
|
||||
telegram |
|
||||
@@ -125,80 +123,87 @@ time | t
|
||||
active | t
|
||||
|
||||
api.logs_view
|
||||
-[ RECORD 1 ]--------------
|
||||
id | 2
|
||||
name | Knipan to Ekenäs
|
||||
from | Knipan
|
||||
to | Ekenäs
|
||||
distance | 8.6862
|
||||
duration | PT18M
|
||||
-[ RECORD 2 ]--------------
|
||||
id | 1
|
||||
name | patch log name 3
|
||||
from | Bollsta
|
||||
to | Slottsbacken
|
||||
distance | 7.17
|
||||
duration | PT25M
|
||||
-[ RECORD 1 ]----+-----------------------
|
||||
id | 2
|
||||
name | Norra hamnen to Ekenäs
|
||||
from | Norra hamnen
|
||||
to | Ekenäs
|
||||
distance | 8.8968
|
||||
duration | PT20M
|
||||
_from_moorage_id | 2
|
||||
_to_moorage_id | 3
|
||||
-[ RECORD 2 ]----+-----------------------
|
||||
id | 1
|
||||
name | patch log name 3
|
||||
from | patch moorage name 3
|
||||
to | Norra hamnen
|
||||
distance | 7.6447
|
||||
duration | PT27M
|
||||
_from_moorage_id | 1
|
||||
_to_moorage_id | 2
|
||||
|
||||
api.stays
|
||||
-[ RECORD 1 ]-------------------------------------------------
|
||||
id | 1
|
||||
vessel_id | t
|
||||
active | f
|
||||
name | patch stay name 3
|
||||
latitude | 60.077666666666666
|
||||
longitude | 23.530866666666668
|
||||
geog | 0101000020E6100000B0DEBBE0E68737404DA938FBF0094E40
|
||||
arrived | t
|
||||
departed | t
|
||||
duration |
|
||||
stay_code | 2
|
||||
notes | new stay note 3
|
||||
-[ RECORD 2 ]-------------------------------------------------
|
||||
id | 2
|
||||
vessel_id | t
|
||||
active | f
|
||||
name | Slottsbacken
|
||||
latitude | 59.97688333333333
|
||||
longitude | 23.4321
|
||||
geog | 0101000020E6100000029A081B9E6E37404A5658830AFD4D40
|
||||
arrived | t
|
||||
departed | t
|
||||
duration |
|
||||
stay_code | 1
|
||||
notes |
|
||||
-[ RECORD 3 ]-------------------------------------------------
|
||||
id | 3
|
||||
vessel_id | t
|
||||
active | t
|
||||
name | Ekenäs
|
||||
latitude | 59.86
|
||||
longitude | 23.365766666666666
|
||||
geog | 0101000020E6100000DE4C5FE2A25D3740AE47E17A14EE4D40
|
||||
arrived | t
|
||||
departed | f
|
||||
duration |
|
||||
stay_code | 2
|
||||
notes |
|
||||
-[ RECORD 1 ]--------------------------------------------------
|
||||
id | 3
|
||||
vessel_id | t
|
||||
moorage_id |
|
||||
active | t
|
||||
name |
|
||||
latitude | 59.86
|
||||
longitude | 23.365766666666666
|
||||
geog |
|
||||
arrived | t
|
||||
departed | f
|
||||
duration |
|
||||
stay_code | 2
|
||||
notes |
|
||||
-[ RECORD 2 ]--------------------------------------------------
|
||||
id | 1
|
||||
vessel_id | t
|
||||
moorage_id | 1
|
||||
active | f
|
||||
name | patch stay name 3
|
||||
latitude | 60.077666666666666
|
||||
longitude | 23.530866666666668
|
||||
geog | 0101000020E6100000B0DEBBE0E68737404DA938FBF0094E40
|
||||
arrived | t
|
||||
departed | t
|
||||
duration | PT1M
|
||||
stay_code | 2
|
||||
notes | new stay note 3
|
||||
-[ RECORD 3 ]--------------------------------------------------
|
||||
id | 2
|
||||
vessel_id | t
|
||||
moorage_id | 2
|
||||
active | f
|
||||
name | 0 days stay at Norra hamnen in November 2023
|
||||
latitude | 59.97688333333333
|
||||
longitude | 23.4321
|
||||
geog | 0101000020E6100000029A081B9E6E37404A5658830AFD4D40
|
||||
arrived | t
|
||||
departed | t
|
||||
duration | PT2M
|
||||
stay_code | 4
|
||||
notes |
|
||||
|
||||
stays_view
|
||||
-[ RECORD 1 ]+------------------
|
||||
-[ RECORD 1 ]+---------------------
|
||||
id | 2
|
||||
name | t
|
||||
moorage | Slottsbacken
|
||||
moorage | Norra hamnen
|
||||
moorage_id | 2
|
||||
duration | PT3M
|
||||
stayed_at | Unknown
|
||||
stayed_at_id | 1
|
||||
duration | PT2M
|
||||
stayed_at | Dock
|
||||
stayed_at_id | 4
|
||||
arrived | t
|
||||
departed | t
|
||||
notes |
|
||||
-[ RECORD 2 ]+------------------
|
||||
-[ RECORD 2 ]+---------------------
|
||||
id | 1
|
||||
name | t
|
||||
moorage | patch stay name 3
|
||||
moorage | patch moorage name 3
|
||||
moorage_id | 1
|
||||
duration | PT2M
|
||||
duration | PT1M
|
||||
stayed_at | Anchor
|
||||
stayed_at_id | 2
|
||||
arrived | t
|
||||
@@ -210,44 +215,57 @@ api.moorages
|
||||
id | 1
|
||||
vessel_id | t
|
||||
name | patch moorage name 3
|
||||
country | fi
|
||||
stay_id | 1
|
||||
country |
|
||||
stay_code | 2
|
||||
stay_duration | PT2M
|
||||
stay_duration | PT1M
|
||||
reference_count | 1
|
||||
latitude | 60.077666666666666
|
||||
longitude | 23.530866666666668
|
||||
geog | 0101000020E6100000B0DEBBE0E68737404DA938FBF0094E40
|
||||
latitude | 60.0776666666667
|
||||
longitude | 23.5308666666667
|
||||
geog | 0101000020E6100000B9DEBBE0E687374052A938FBF0094E40
|
||||
home_flag | t
|
||||
notes | new moorage note 3
|
||||
-[ RECORD 2 ]---+---------------------------------------------------
|
||||
id | 2
|
||||
vessel_id | t
|
||||
name | Slottsbacken
|
||||
country | fi
|
||||
stay_id | 2
|
||||
stay_code | 1
|
||||
stay_duration | PT3M
|
||||
reference_count | 1
|
||||
latitude | 59.97688333333333
|
||||
name | Norra hamnen
|
||||
country |
|
||||
stay_code | 4
|
||||
stay_duration | PT2M
|
||||
reference_count | 2
|
||||
latitude | 59.9768833333333
|
||||
longitude | 23.4321
|
||||
geog | 0101000020E6100000029A081B9E6E37404A5658830AFD4D40
|
||||
geog | 0101000020E6100000029A081B9E6E3740455658830AFD4D40
|
||||
home_flag | f
|
||||
notes |
|
||||
-[ RECORD 3 ]---+---------------------------------------------------
|
||||
id | 3
|
||||
vessel_id | t
|
||||
name | Ekenäs
|
||||
country | fi
|
||||
stay_code | 1
|
||||
stay_duration |
|
||||
reference_count | 1
|
||||
latitude | 59.86
|
||||
longitude | 23.3657666666667
|
||||
geog | 0101000020E6100000E84C5FE2A25D3740AE47E17A14EE4D40
|
||||
home_flag | f
|
||||
notes |
|
||||
|
||||
api.moorages_view
|
||||
-[ RECORD 1 ]-------+---------------------
|
||||
id | 2
|
||||
moorage | Norra hamnen
|
||||
default_stay | Dock
|
||||
default_stay_id | 4
|
||||
total_stay | 0
|
||||
total_duration | PT2M
|
||||
arrivals_departures | 2
|
||||
-[ RECORD 2 ]-------+---------------------
|
||||
id | 1
|
||||
moorage | patch moorage name 3
|
||||
default_stay | Anchor
|
||||
default_stay_id | 2
|
||||
total_stay | 0
|
||||
arrivals_departures | 1
|
||||
-[ RECORD 2 ]-------+---------------------
|
||||
id | 2
|
||||
moorage | Slottsbacken
|
||||
default_stay | Unknown
|
||||
default_stay_id | 1
|
||||
total_stay | 0
|
||||
total_duration | PT1M
|
||||
arrivals_departures | 1
|
||||
|
||||
|
@@ -22,15 +22,15 @@ count | 21
|
||||
|
||||
Test monitoring_view3 for user
|
||||
-[ RECORD 1 ]
|
||||
count | 3682
|
||||
count | 3736
|
||||
|
||||
Test monitoring_voltage for user
|
||||
-[ RECORD 1 ]
|
||||
count | 46
|
||||
count | 47
|
||||
|
||||
Test monitoring_temperatures for user
|
||||
-[ RECORD 1 ]
|
||||
count | 119
|
||||
count | 120
|
||||
|
||||
Test monitoring_humidity for user
|
||||
-[ RECORD 1 ]
|
||||
|
@@ -6,7 +6,7 @@
|
||||
You are now connected to database "signalk" as user "username".
|
||||
Expanded display is on.
|
||||
-[ RECORD 1 ]--+-------------------------------
|
||||
server_version | 15.4 (Debian 15.4-2.pgdg110+1)
|
||||
server_version | 15.5 (Debian 15.5-1.pgdg110+1)
|
||||
|
||||
-[ RECORD 1 ]--------+----------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------------
|
||||
postgis_full_version | POSTGIS="3.4.0 0874ea3" [EXTENSION] PGSQL="150" GEOS="3.9.0-CAPI-1.16.2" PROJ="7.2.1 NETWORK_ENABLED=OFF URL_ENDPOINT=https://cdn.proj.org USER_WRITABLE_DIRECTORY=/var/lib/postgresql/.local/share/proj DATABASE_PATH=/usr/share/proj/proj.db" LIBXML="2.9.10" LIBJSON="0.15" LIBPROTOBUF="1.3.3" WAGYU="0.5.0 (Internal)"
|
||||
@@ -322,15 +322,6 @@ qual | (vessel_id = current_setting('vessel.id'::text, false))
|
||||
with_check | true
|
||||
-[ RECORD 9 ]------------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | api
|
||||
tablename | moorages
|
||||
policyname | admin_all
|
||||
permissive | PERMISSIVE
|
||||
roles | {username}
|
||||
cmd | ALL
|
||||
qual | true
|
||||
with_check | true
|
||||
-[ RECORD 10 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | api
|
||||
tablename | metrics
|
||||
policyname | api_user_role
|
||||
permissive | PERMISSIVE
|
||||
@@ -338,7 +329,7 @@ roles | {user_role}
|
||||
cmd | ALL
|
||||
qual | (vessel_id = current_setting('vessel.id'::text, true))
|
||||
with_check | (vessel_id = current_setting('vessel.id'::text, false))
|
||||
-[ RECORD 11 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
-[ RECORD 10 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | api
|
||||
tablename | metrics
|
||||
policyname | api_scheduler_role
|
||||
@@ -347,7 +338,7 @@ roles | {scheduler}
|
||||
cmd | ALL
|
||||
qual | (vessel_id = current_setting('vessel.id'::text, false))
|
||||
with_check | (vessel_id = current_setting('vessel.id'::text, false))
|
||||
-[ RECORD 12 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
-[ RECORD 11 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | api
|
||||
tablename | metrics
|
||||
policyname | grafana_role
|
||||
@@ -356,6 +347,15 @@ roles | {grafana}
|
||||
cmd | ALL
|
||||
qual | (vessel_id = current_setting('vessel.id'::text, false))
|
||||
with_check | false
|
||||
-[ RECORD 12 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | api
|
||||
tablename | metrics
|
||||
policyname | api_anonymous_role
|
||||
permissive | PERMISSIVE
|
||||
roles | {api_anonymous}
|
||||
cmd | ALL
|
||||
qual | (vessel_id = current_setting('vessel.id'::text, false))
|
||||
with_check | false
|
||||
-[ RECORD 13 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | api
|
||||
tablename | logbook
|
||||
@@ -384,24 +384,6 @@ cmd | ALL
|
||||
qual | (vessel_id = current_setting('vessel.id'::text, true))
|
||||
with_check | (vessel_id = current_setting('vessel.id'::text, false))
|
||||
-[ RECORD 16 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | auth
|
||||
tablename | vessels
|
||||
policyname | grafana_proxy_role
|
||||
permissive | PERMISSIVE
|
||||
roles | {grafana_auth}
|
||||
cmd | ALL
|
||||
qual | true
|
||||
with_check | false
|
||||
-[ RECORD 17 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | auth
|
||||
tablename | accounts
|
||||
policyname | admin_all
|
||||
permissive | PERMISSIVE
|
||||
roles | {username}
|
||||
cmd | ALL
|
||||
qual | true
|
||||
with_check | true
|
||||
-[ RECORD 18 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | api
|
||||
tablename | logbook
|
||||
policyname | api_scheduler_role
|
||||
@@ -410,7 +392,7 @@ roles | {scheduler}
|
||||
cmd | ALL
|
||||
qual | (vessel_id = current_setting('vessel.id'::text, false))
|
||||
with_check | (vessel_id = current_setting('vessel.id'::text, false))
|
||||
-[ RECORD 19 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
-[ RECORD 17 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | api
|
||||
tablename | logbook
|
||||
policyname | grafana_role
|
||||
@@ -419,7 +401,16 @@ roles | {grafana}
|
||||
cmd | ALL
|
||||
qual | (vessel_id = current_setting('vessel.id'::text, false))
|
||||
with_check | false
|
||||
-[ RECORD 20 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
-[ RECORD 18 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | api
|
||||
tablename | logbook
|
||||
policyname | api_anonymous_role
|
||||
permissive | PERMISSIVE
|
||||
roles | {api_anonymous}
|
||||
cmd | ALL
|
||||
qual | (vessel_id = current_setting('vessel.id'::text, false))
|
||||
with_check | false
|
||||
-[ RECORD 19 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | api
|
||||
tablename | stays
|
||||
policyname | admin_all
|
||||
@@ -428,7 +419,7 @@ roles | {username}
|
||||
cmd | ALL
|
||||
qual | true
|
||||
with_check | true
|
||||
-[ RECORD 21 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
-[ RECORD 20 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | api
|
||||
tablename | stays
|
||||
policyname | api_vessel_role
|
||||
@@ -437,7 +428,7 @@ roles | {vessel_role}
|
||||
cmd | ALL
|
||||
qual | (vessel_id = current_setting('vessel.id'::text, false))
|
||||
with_check | true
|
||||
-[ RECORD 22 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
-[ RECORD 21 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | api
|
||||
tablename | stays
|
||||
policyname | api_user_role
|
||||
@@ -446,7 +437,7 @@ roles | {user_role}
|
||||
cmd | ALL
|
||||
qual | (vessel_id = current_setting('vessel.id'::text, true))
|
||||
with_check | (vessel_id = current_setting('vessel.id'::text, false))
|
||||
-[ RECORD 23 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
-[ RECORD 22 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | api
|
||||
tablename | stays
|
||||
policyname | api_scheduler_role
|
||||
@@ -455,7 +446,7 @@ roles | {scheduler}
|
||||
cmd | ALL
|
||||
qual | (vessel_id = current_setting('vessel.id'::text, false))
|
||||
with_check | (vessel_id = current_setting('vessel.id'::text, false))
|
||||
-[ RECORD 24 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
-[ RECORD 23 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | api
|
||||
tablename | stays
|
||||
policyname | grafana_role
|
||||
@@ -464,6 +455,15 @@ roles | {grafana}
|
||||
cmd | ALL
|
||||
qual | (vessel_id = current_setting('vessel.id'::text, false))
|
||||
with_check | false
|
||||
-[ RECORD 24 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | api
|
||||
tablename | moorages
|
||||
policyname | admin_all
|
||||
permissive | PERMISSIVE
|
||||
roles | {username}
|
||||
cmd | ALL
|
||||
qual | true
|
||||
with_check | true
|
||||
-[ RECORD 25 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | api
|
||||
tablename | moorages
|
||||
@@ -529,6 +529,24 @@ qual | ((owner_email)::text = current_setting('user.email'::text, true))
|
||||
with_check | false
|
||||
-[ RECORD 32 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | auth
|
||||
tablename | vessels
|
||||
policyname | grafana_proxy_role
|
||||
permissive | PERMISSIVE
|
||||
roles | {grafana_auth}
|
||||
cmd | ALL
|
||||
qual | true
|
||||
with_check | false
|
||||
-[ RECORD 33 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | auth
|
||||
tablename | accounts
|
||||
policyname | admin_all
|
||||
permissive | PERMISSIVE
|
||||
roles | {username}
|
||||
cmd | ALL
|
||||
qual | true
|
||||
with_check | true
|
||||
-[ RECORD 34 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | auth
|
||||
tablename | accounts
|
||||
policyname | api_user_role
|
||||
permissive | PERMISSIVE
|
||||
@@ -536,7 +554,7 @@ roles | {user_role}
|
||||
cmd | ALL
|
||||
qual | ((email)::text = current_setting('user.email'::text, true))
|
||||
with_check | ((email)::text = current_setting('user.email'::text, true))
|
||||
-[ RECORD 33 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
-[ RECORD 35 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | auth
|
||||
tablename | accounts
|
||||
policyname | api_scheduler_role
|
||||
@@ -545,7 +563,7 @@ roles | {scheduler}
|
||||
cmd | ALL
|
||||
qual | ((email)::text = current_setting('user.email'::text, true))
|
||||
with_check | ((email)::text = current_setting('user.email'::text, true))
|
||||
-[ RECORD 34 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
-[ RECORD 36 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | auth
|
||||
tablename | accounts
|
||||
policyname | grafana_proxy_role
|
||||
@@ -554,7 +572,7 @@ roles | {grafana_auth}
|
||||
cmd | ALL
|
||||
qual | true
|
||||
with_check | false
|
||||
-[ RECORD 35 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
-[ RECORD 37 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | public
|
||||
tablename | process_queue
|
||||
policyname | admin_all
|
||||
@@ -563,7 +581,7 @@ roles | {username}
|
||||
cmd | ALL
|
||||
qual | true
|
||||
with_check | true
|
||||
-[ RECORD 36 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
-[ RECORD 38 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | public
|
||||
tablename | process_queue
|
||||
policyname | api_vessel_role
|
||||
@@ -572,7 +590,7 @@ roles | {vessel_role}
|
||||
cmd | ALL
|
||||
qual | ((ref_id = current_setting('user.id'::text, true)) OR (ref_id = current_setting('vessel.id'::text, true)))
|
||||
with_check | true
|
||||
-[ RECORD 37 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
-[ RECORD 39 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | public
|
||||
tablename | process_queue
|
||||
policyname | api_user_role
|
||||
@@ -581,7 +599,7 @@ roles | {user_role}
|
||||
cmd | ALL
|
||||
qual | ((ref_id = current_setting('user.id'::text, true)) OR (ref_id = current_setting('vessel.id'::text, true)))
|
||||
with_check | ((ref_id = current_setting('user.id'::text, true)) OR (ref_id = current_setting('vessel.id'::text, true)))
|
||||
-[ RECORD 38 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
-[ RECORD 40 ]-----------------------------------------------------------------------------------------------------------------------------
|
||||
schemaname | public
|
||||
tablename | process_queue
|
||||
policyname | api_scheduler_role
|
||||
@@ -597,11 +615,11 @@ reverse_geocode_py_fn | {"name": "Spain", "country_code": "es"}
|
||||
|
||||
Test geoip reverse_geoip_py_fn
|
||||
-[ RECORD 1 ]----------------------------------------------------------------------------------------------------------------------------------------------
|
||||
versions_fn | {"api_version" : "0.4.1", "sys_version" : "PostgreSQL 15.4", "timescaledb" : "2.12.2", "postgis" : "3.4.0", "postgrest" : "PostgREST 11.2.2"}
|
||||
versions_fn | {"api_version" : "0.5.0", "sys_version" : "PostgreSQL 15.5", "timescaledb" : "2.12.2", "postgis" : "3.4.0", "postgrest" : "PostgREST 11.2.2"}
|
||||
|
||||
-[ RECORD 1 ]-----------------
|
||||
api_version | 0.4.1
|
||||
sys_version | PostgreSQL 15.4
|
||||
api_version | 0.5.0
|
||||
sys_version | PostgreSQL 15.5
|
||||
timescaledb | 2.12.2
|
||||
postgis | 3.4.0
|
||||
postgrest | PostgREST 11.2.2
|
||||
|
@@ -9,8 +9,20 @@ if [[ -z "${PGSAIL_API_URI}" ]]; then
|
||||
exit 1
|
||||
fi
|
||||
|
||||
#npm install
|
||||
npm install -g pnpm && pnpm install
|
||||
# go install
|
||||
if [[ ! -x "/usr/bin/go" || ! -x "/root/go/bin/mermerd" ]]; then
|
||||
#wget -q https://go.dev/dl/go1.21.4.linux-arm64.tar.gz && \
|
||||
#rm -rf /usr/local/go && tar -C /usr/local -xzf go1.21.4.linux-arm64.tar.gz && \
|
||||
apt update && apt -y install golang && \
|
||||
go install github.com/KarnerTh/mermerd@latest
|
||||
fi
|
||||
|
||||
# pnpm install
|
||||
if [[ ! -x "/usr/local/bin/pnpm" ]]; then
|
||||
npm install -g pnpm
|
||||
fi
|
||||
pnpm install || exit 1
|
||||
|
||||
# settings
|
||||
export mymocha="./node_modules/mocha/bin/_mocha"
|
||||
mkdir -p output/ && rm -rf output/*
|
||||
@@ -129,6 +141,14 @@ else
|
||||
exit 1
|
||||
fi
|
||||
|
||||
$mymocha index5.js --reporter ./node_modules/mochawesome --reporter-options reportDir=output/,reportFilename=report5.html
|
||||
if [ $? -eq 0 ]; then
|
||||
echo OK
|
||||
else
|
||||
echo mocha index5.js
|
||||
exit 1
|
||||
fi
|
||||
|
||||
# Monitoring unit tests
|
||||
psql ${PGSAIL_DB_URI} < sql/monitoring.sql > output/monitoring.sql.output
|
||||
diff sql/monitoring.sql.output output/monitoring.sql.output > /dev/null
|
||||
@@ -143,11 +163,24 @@ else
|
||||
fi
|
||||
|
||||
# Download and update openapi documentation
|
||||
wget ${PGSAIL_API_URI} -O ../openapi.json
|
||||
wget ${PGSAIL_API_URI} -O openapi.json
|
||||
#echo 0
|
||||
if [ $? -eq 0 ]; then
|
||||
cp openapi.json ../openapi.json
|
||||
echo openapi.json OK
|
||||
else
|
||||
echo openapi.json FAILED
|
||||
exit 1
|
||||
fi
|
||||
|
||||
# Generate and update mermaid schema documentation
|
||||
/root/go/bin/mermerd --runConfig ../ERD/mermerdConfig.yaml
|
||||
echo $?
|
||||
echo 0
|
||||
if [ $? -eq 0 ]; then
|
||||
cp postgsail.md ../ERD/postgsail.md
|
||||
echo postgsail.md OK
|
||||
else
|
||||
echo postgsail.md FAILED
|
||||
exit 1
|
||||
fi
|
||||
|
Reference in New Issue
Block a user