Skip to content

Commit 5409f1e

Browse files
committed
Update migration 202412:
- Update api.export_logbooks_geojson_point_trips_fn, - Update export_logbook_geojson_trip_fn, update geojson from trip to geojson with more properties
1 parent e5491ae commit 5409f1e

File tree

1 file changed

+164
-4
lines changed

1 file changed

+164
-4
lines changed

initdb/99_migrations_202412.sql

Lines changed: 164 additions & 4 deletions
Original file line numberDiff line numberDiff line change
@@ -797,9 +797,131 @@ COMMENT ON FUNCTION
797797
api.merge_logbook_fn
798798
IS 'Merge 2 logbook by id, from the start of the lower log id and the end of the higher log id, update the calculate data as well (avg, geojson)';
799799

800-
-- Update export_logbook_geojson_trip_fn, update geojson from trip to geojson
800+
-- Update export_logbook_geojson_trip_fn, update geojson from trip to geojson with more properties
801+
DROP FUNCTION api.export_logbook_geojson_trip_fn;
801802
CREATE OR REPLACE FUNCTION api.export_logbook_geojson_trip_fn(_id integer)
802-
RETURNS json
803+
RETURNS jsonb
804+
LANGUAGE plpgsql
805+
AS $function$
806+
DECLARE
807+
logbook_rec RECORD;
808+
log_geojson JSONB;
809+
metrics_geojson JSONB;
810+
first_feature_obj JSONB;
811+
second_feature_note JSONB;
812+
last_feature_note JSONB;
813+
BEGIN
814+
-- Validate input
815+
IF _id IS NULL OR _id < 1 THEN
816+
RAISE WARNING '-> export_logbook_geojson_trip_fn invalid input %', _id;
817+
RETURN NULL;
818+
END IF;
819+
820+
-- Fetch the processed logbook data.
821+
SELECT id, name, distance, duration, avg_speed, max_speed, max_wind_speed, extra->>'avg_wind_speed' AS avg_wind_speed,
822+
_from, _to, _from_time, _to_time, _from_moorage_id, _to_moorage_id, notes,
823+
trajectory(trip) AS trajectory,
824+
timestamps(trip) AS times
825+
INTO logbook_rec
826+
FROM api.logbook
827+
WHERE id = _id;
828+
829+
-- Create JSON notes for feature properties
830+
first_feature_obj := jsonb_build_object('trip', jsonb_build_object('name', logbook_rec.name, 'duration', logbook_rec.duration, 'distance', logbook_rec.distance));
831+
second_feature_note := jsonb_build_object('notes', COALESCE(logbook_rec._from, ''));
832+
last_feature_note := jsonb_build_object('notes', COALESCE(logbook_rec._to, ''));
833+
834+
-- GeoJSON Feature for Logbook linestring
835+
SELECT ST_AsGeoJSON(logbook_rec.*)::jsonb INTO log_geojson;
836+
837+
-- GeoJSON Features for Metrics Points
838+
SELECT jsonb_agg(ST_AsGeoJSON(t.*)::jsonb) INTO metrics_geojson
839+
FROM (
840+
SELECT
841+
geometry(getvalue(points.point)) AS point_geometry,
842+
getTimestamp(points.point) AS time,
843+
valueAtTimestamp(points.trip_cog, getTimestamp(points.point)) AS courseovergroundtrue,
844+
valueAtTimestamp(points.trip_sog, getTimestamp(points.point)) AS speedoverground,
845+
valueAtTimestamp(points.trip_twa, getTimestamp(points.point)) AS windspeedapparent,
846+
valueAtTimestamp(points.trip_tws, getTimestamp(points.point)) AS truewindspeed,
847+
valueAtTimestamp(points.trip_twd, getTimestamp(points.point)) AS truewinddirection,
848+
valueAtTimestamp(points.trip_notes, getTimestamp(points.point)) AS notes,
849+
valueAtTimestamp(points.trip_status, getTimestamp(points.point)) AS status,
850+
valueAtTimestamp(points.trip_depth, getTimestamp(points.point)) AS depth,
851+
valueAtTimestamp(points.trip_batt_charge, getTimestamp(points.point)) AS stateofcharge,
852+
valueAtTimestamp(points.trip_batt_voltage, getTimestamp(points.point)) AS voltage,
853+
valueAtTimestamp(points.trip_temp_water, getTimestamp(points.point)) AS watertemperature,
854+
valueAtTimestamp(points.trip_temp_out, getTimestamp(points.point)) AS outsidetemperature,
855+
valueAtTimestamp(points.trip_pres_out, getTimestamp(points.point)) AS outsidepressure,
856+
valueAtTimestamp(points.trip_hum_out, getTimestamp(points.point)) AS outsidehumidity
857+
FROM (
858+
SELECT unnest(instants(trip)) AS point,
859+
trip_cog,
860+
trip_sog,
861+
trip_twa,
862+
trip_tws,
863+
trip_twd,
864+
trip_notes,
865+
trip_status,
866+
trip_depth,
867+
trip_batt_charge,
868+
trip_batt_voltage,
869+
trip_temp_water,
870+
trip_temp_out,
871+
trip_pres_out,
872+
trip_hum_out
873+
FROM api.logbook
874+
WHERE id = _id
875+
AND trip IS NOT NULL
876+
) AS points
877+
) AS t;
878+
879+
-- Update the properties of the first feature
880+
metrics_geojson := jsonb_set(
881+
metrics_geojson,
882+
'{0, properties}',
883+
(metrics_geojson->0->'properties' || first_feature_obj)::jsonb,
884+
true
885+
);
886+
-- Update the properties of the third feature
887+
metrics_geojson := jsonb_set(
888+
metrics_geojson,
889+
'{1, properties}',
890+
CASE
891+
WHEN (metrics_geojson->1->'properties'->>'notes') = '' THEN
892+
(metrics_geojson->1->'properties' || second_feature_note)::jsonb
893+
ELSE
894+
metrics_geojson->1->'properties'
895+
END,
896+
true
897+
);
898+
-- Update the properties of the last feature
899+
metrics_geojson := jsonb_set(
900+
metrics_geojson,
901+
'{-1, properties}',
902+
CASE
903+
WHEN (metrics_geojson->-1->'properties'->>'notes') = '' THEN
904+
(metrics_geojson->-1->'properties' || last_feature_note)::jsonb
905+
ELSE
906+
metrics_geojson->-1->'properties'
907+
END,
908+
true
909+
);
910+
911+
-- Combine Logbook and Metrics GeoJSON
912+
RETURN jsonb_build_object('type', 'FeatureCollection', 'features', log_geojson || metrics_geojson);
913+
914+
END;
915+
$function$
916+
;
917+
-- Description
918+
COMMENT ON FUNCTION
919+
api.export_logbook_geojson_trip_fn
920+
IS 'Export a log trip entry to GEOJSON format with custom properties for timelapse replay';
921+
922+
-- Add export_logbook_metrics_trip_fn, update geojson from trip to geojson
923+
CREATE OR REPLACE FUNCTION api.export_logbook_metrics_trip_fn(_id integer)
924+
RETURNS jsonb
803925
LANGUAGE plpgsql
804926
AS $function$
805927
DECLARE
@@ -906,7 +1028,7 @@ BEGIN
9061028
END;
9071029
$function$
9081030
;
909-
COMMENT ON FUNCTION api.export_logbook_geojson_trip_fn IS 'Export a logs entries to GeoJSON format of geometry point';
1031+
COMMENT ON FUNCTION api.export_logbook_metrics_trip_fn IS 'Export a log entry to an array of GeoJSON feature format of geometry point';
9101032

9111033
-- Create api.export_logbook_geojson_point_trip_fn, transform spatiotemporal trip into a geojson with the corresponding properties
9121034
CREATE OR REPLACE FUNCTION api.export_logbook_geojson_point_trip_fn(_id integer)
@@ -2081,6 +2203,44 @@ END;
20812203
$$ LANGUAGE plpgsql;
20822204
COMMENT ON FUNCTION api.delete_trip_entry_fn IS 'Delete at a specific time a temporal sequence for all trip_* column from a logbook';
20832205

2206+
-- Update export_logbooks_geojson_point_trips_fn, replace timelapse2_fn, Generate the GeoJSON from the time sequence value
2207+
CREATE OR REPLACE FUNCTION api.export_logbooks_geojson_point_trips_fn(
2208+
start_log integer DEFAULT NULL::integer,
2209+
end_log integer DEFAULT NULL::integer,
2210+
start_date text DEFAULT NULL::text,
2211+
end_date text DEFAULT NULL::text,
2212+
OUT geojson jsonb
2213+
) RETURNS jsonb
2214+
LANGUAGE plpgsql
2215+
AS $function$
2216+
DECLARE
2217+
metrics_geojson jsonb;
2218+
BEGIN
2219+
-- Normalize start and end values
2220+
IF start_log IS NOT NULL AND end_log IS NULL THEN end_log := start_log; END IF;
2221+
IF start_date IS NOT NULL AND end_date IS NULL THEN end_date := start_date; END IF;
2222+
2223+
WITH logbook_data AS (
2224+
-- get the logbook data, an array for each log
2225+
SELECT api.export_logbook_metrics_trip_fn(l.id) AS log_geojson
2226+
FROM api.logbook l
2227+
WHERE (start_log IS NULL OR l.id >= start_log) AND
2228+
(end_log IS NULL OR l.id <= end_log) AND
2229+
(start_date IS NULL OR l._from_time >= start_date::TIMESTAMPTZ) AND
2230+
(end_date IS NULL OR l._to_time <= end_date::TIMESTAMPTZ + interval '23 hours 59 minutes') AND
2231+
l.trip IS NOT NULL
2232+
ORDER BY l._from_time ASC
2233+
)
2234+
-- Create the GeoJSON response
2235+
SELECT jsonb_build_object(
2236+
'type', 'FeatureCollection',
2237+
'features', jsonb_agg(feature_element)) INTO geojson
2238+
FROM logbook_data l,
2239+
LATERAL jsonb_array_elements(l.log_geojson) AS feature_element; -- Flatten the arrays and create a GeoJSON FeatureCollection
2240+
END;
2241+
$function$;
2242+
COMMENT ON FUNCTION api.export_logbooks_geojson_point_trips_fn IS 'Export all selected logs into a geojson `trip` to a geojson as points including properties';
2243+
20842244
-- Update api role SQL connection to 40
20852245
ALTER ROLE authenticator WITH NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOBYPASSRLS NOREPLICATION CONNECTION LIMIT 40 LOGIN;
20862246
ALTER ROLE api_anonymous WITH NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOBYPASSRLS NOREPLICATION CONNECTION LIMIT 40 LOGIN;
@@ -2092,8 +2252,8 @@ GRANT UPDATE (name, _from, _to, notes, trip_notes, trip, trip_cog, trip_sog, tri
20922252
GRANT SELECT ON TABLE api.log_view TO api_anonymous;
20932253
GRANT EXECUTE ON FUNCTION api.export_logbooks_geojson_linestring_trips_fn to api_anonymous;
20942254
GRANT EXECUTE ON FUNCTION api.export_logbooks_geojson_point_trips_fn to api_anonymous;
2095-
--GRANT EXECUTE ON FUNCTION api.logbook_update_geojson_trip_fn to api_anonymous;
20962255
GRANT EXECUTE ON FUNCTION api.export_logbook_geojson_trip_fn to api_anonymous;
2256+
GRANT EXECUTE ON FUNCTION api.export_logbook_metrics_trip_fn to api_anonymous;
20972257
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public TO api_anonymous;
20982258
GRANT SELECT ON TABLE api.log_view TO grafana;
20992259
GRANT SELECT ON TABLE api.moorages_view TO grafana;

0 commit comments

Comments
 (0)