Skip to content

Commit aa7608e

Browse files
committed
Update migration 202412
- Update api.stats_fn, due to reference_count and stay_duration columns removal - Update api.stats_stays_fn, due to reference_count and stay_duration columns removal - Update log_view with dynamic GeoJSON, change geojson export fn - Update delete_trip_entry_fn, support additional temporal sequence columns (depth,etc...) - Update export_logbook_geojson_trip_fn, update geojson from trip to geojson additional temporal sequence columns (depth,etc...) - Update api.export_logbook_geojson_point_trip_fn, update geojson from trip to geojson additional temporal sequence columns (depth,etc...)
1 parent 9575eba commit aa7608e

File tree

1 file changed

+275
-5
lines changed

1 file changed

+275
-5
lines changed

initdb/99_migrations_202412.sql

+275-5
Original file line numberDiff line numberDiff line change
@@ -838,7 +838,14 @@ BEGIN
838838
valueAtTimestamp(points.trip_tws, getTimestamp(points.point)) AS truewindspeed,
839839
valueAtTimestamp(points.trip_twd, getTimestamp(points.point)) AS truewinddirection,
840840
valueAtTimestamp(points.trip_notes, getTimestamp(points.point)) AS notes,
841-
valueAtTimestamp(points.trip_status, getTimestamp(points.point)) AS status
841+
valueAtTimestamp(points.trip_status, getTimestamp(points.point)) AS status,
842+
valueAtTimestamp(points.trip_depth, getTimestamp(points.point)) AS depth,
843+
valueAtTimestamp(points.trip_batt_charge, getTimestamp(points.point)) AS stateofcharge,
844+
valueAtTimestamp(points.trip_batt_voltage, getTimestamp(points.point)) AS voltage,
845+
valueAtTimestamp(points.trip_temp_water, getTimestamp(points.point)) AS watertemperature,
846+
valueAtTimestamp(points.trip_temp_out, getTimestamp(points.point)) AS outsidetemperature,
847+
valueAtTimestamp(points.trip_pres_out, getTimestamp(points.point)) AS outsidepressure,
848+
valueAtTimestamp(points.trip_hum_out, getTimestamp(points.point)) AS outsidehumidity
842849
FROM (
843850
SELECT unnest(instants(trip)) AS point,
844851
trip_cog,
@@ -847,7 +854,14 @@ BEGIN
847854
trip_tws,
848855
trip_twd,
849856
trip_notes,
850-
trip_status
857+
trip_status,
858+
trip_depth,
859+
trip_batt_charge,
860+
trip_batt_voltage,
861+
trip_temp_water,
862+
trip_temp_out,
863+
trip_pres_out,
864+
trip_hum_out
851865
FROM api.logbook
852866
WHERE id = _id
853867
AND trip IS NOT NULL
@@ -914,7 +928,14 @@ BEGIN
914928
valueAtTimestamp(points.trip_tws, getTimestamp(points.point)) AS truewindspeed,
915929
valueAtTimestamp(points.trip_twd, getTimestamp(points.point)) AS truewinddirection,
916930
valueAtTimestamp(points.trip_notes, getTimestamp(points.point)) AS notes,
917-
valueAtTimestamp(points.trip_status, getTimestamp(points.point)) AS status
931+
valueAtTimestamp(points.trip_status, getTimestamp(points.point)) AS status,
932+
valueAtTimestamp(points.trip_depth, getTimestamp(points.point)) AS depth,
933+
valueAtTimestamp(points.trip_batt_charge, getTimestamp(points.point)) AS stateofcharge,
934+
valueAtTimestamp(points.trip_batt_voltage, getTimestamp(points.point)) AS voltage,
935+
valueAtTimestamp(points.trip_temp_water, getTimestamp(points.point)) AS watertemperature,
936+
valueAtTimestamp(points.trip_temp_out, getTimestamp(points.point)) AS outsidetemperature,
937+
valueAtTimestamp(points.trip_pres_out, getTimestamp(points.point)) AS outsidepressure,
938+
valueAtTimestamp(points.trip_hum_out, getTimestamp(points.point)) AS outsidehumidity
918939
FROM
919940
(
920941
SELECT
@@ -925,7 +946,14 @@ BEGIN
925946
trip_tws,
926947
trip_twd,
927948
trip_notes,
928-
trip_status
949+
trip_status,
950+
trip_depth,
951+
trip_batt_charge,
952+
trip_batt_voltage,
953+
trip_temp_water,
954+
trip_temp_out,
955+
trip_pres_out,
956+
trip_hum_out
929957
FROM api.logbook
930958
WHERE id = _id
931959
) AS points
@@ -1814,15 +1842,257 @@ $function$
18141842

18151843
COMMENT ON FUNCTION public.qgis_bbox_trip_py_fn(in text, out text) IS 'Generate the BBOX base on trip extent and adapt extent to the image size for QGIS Server';
18161844

1845+
-- DROP FUNCTION api.stats_stays_fn(in text, in text, out json);
1846+
-- Update api.stats_stays_fn, due to reference_count and stay_duration columns removal
1847+
CREATE OR REPLACE FUNCTION api.stats_stays_fn(start_date text DEFAULT NULL::text, end_date text DEFAULT NULL::text, OUT stats json)
1848+
RETURNS json
1849+
LANGUAGE plpgsql
1850+
AS $function$
1851+
DECLARE
1852+
_start_date TIMESTAMPTZ DEFAULT '1970-01-01';
1853+
_end_date TIMESTAMPTZ DEFAULT NOW();
1854+
BEGIN
1855+
IF start_date IS NOT NULL AND public.isdate(start_date::text) AND public.isdate(end_date::text) THEN
1856+
RAISE NOTICE '--> stats_stays_fn, custom filter result stats by date [%]', start_date;
1857+
_start_date := start_date::TIMESTAMPTZ;
1858+
_end_date := end_date::TIMESTAMPTZ;
1859+
END IF;
1860+
RAISE NOTICE '--> stats_stays_fn, _start_date [%], _end_date [%]', _start_date, _end_date;
1861+
WITH
1862+
stays AS (
1863+
SELECT distinct(moorage_id) as moorage_id, sum(duration) as duration, count(id) as reference_count
1864+
FROM api.stays s
1865+
WHERE arrived >= _start_date::TIMESTAMPTZ
1866+
AND departed <= _end_date::TIMESTAMPTZ + interval '23 hours 59 minutes'
1867+
group by moorage_id
1868+
order by moorage_id
1869+
),
1870+
moorages AS (
1871+
SELECT m.id, m.home_flag, mv.stays_count, mv.stays_sum_duration, m.stay_code, m.country, s.duration, s.reference_count
1872+
FROM api.moorages m, stays s, api.moorage_view mv
1873+
WHERE s.moorage_id = m.id
1874+
and mv.id = m.id
1875+
order by moorage_id
1876+
),
1877+
home_ports AS (
1878+
select count(*) as home_ports from api.moorages m where home_flag is true
1879+
),
1880+
unique_moorages AS (
1881+
select count(*) as unique_moorages from api.moorages m
1882+
),
1883+
time_at_home_ports AS (
1884+
select sum(m.stays_sum_duration) as time_at_home_ports from api.moorage_view m where home is true
1885+
),
1886+
sum_stay_duration AS (
1887+
select sum(m.stays_sum_duration) as sum_stay_duration from api.moorage_view m where home is false
1888+
),
1889+
time_spent_away_arr AS (
1890+
select m.default_stay_id as stay_code,sum(m.stays_sum_duration) as stay_duration from api.moorage_view m where home is false group by m.default_stay_id order by m.default_stay_id
1891+
),
1892+
time_spent_arr as (
1893+
select jsonb_agg(t.*) as time_spent_away_arr from time_spent_away_arr t
1894+
),
1895+
time_spent_away AS (
1896+
select sum(m.stays_sum_duration) as time_spent_away from api.moorage_view m where home is false
1897+
),
1898+
time_spent as (
1899+
select jsonb_agg(t.*) as time_spent_away from time_spent_away t
1900+
)
1901+
-- Return a JSON
1902+
SELECT jsonb_build_object(
1903+
'home_ports', home_ports.home_ports,
1904+
'unique_moorages', unique_moorages.unique_moorages,
1905+
'time_at_home_ports', time_at_home_ports.time_at_home_ports,
1906+
'time_spent_away', time_spent_away.time_spent_away,
1907+
'time_spent_away_arr', time_spent_arr.time_spent_away_arr) INTO stats
1908+
FROM home_ports, unique_moorages,
1909+
time_at_home_ports, sum_stay_duration, time_spent_away, time_spent_arr;
1910+
END;
1911+
$function$
1912+
;
1913+
1914+
COMMENT ON FUNCTION api.stats_stays_fn(in text, in text, out json) IS 'Stays/Moorages stats by date';
1915+
1916+
-- DROP FUNCTION api.stats_fn(in text, in text, out jsonb);
1917+
-- Update api.stats_fn, due to reference_count and stay_duration columns removal
1918+
CREATE OR REPLACE FUNCTION api.stats_fn(start_date text DEFAULT NULL::text, end_date text DEFAULT NULL::text, OUT stats jsonb)
1919+
RETURNS jsonb
1920+
LANGUAGE plpgsql
1921+
AS $function$
1922+
DECLARE
1923+
_start_date TIMESTAMPTZ DEFAULT '1970-01-01';
1924+
_end_date TIMESTAMPTZ DEFAULT NOW();
1925+
stats_logs JSONB;
1926+
stats_moorages JSONB;
1927+
stats_logs_topby JSONB;
1928+
stats_moorages_topby JSONB;
1929+
BEGIN
1930+
IF start_date IS NOT NULL AND public.isdate(start_date::text) AND public.isdate(end_date::text) THEN
1931+
RAISE WARNING '--> stats_fn, filter result stats by date [%]', start_date;
1932+
_start_date := start_date::TIMESTAMPTZ;
1933+
_end_date := end_date::TIMESTAMPTZ;
1934+
END IF;
1935+
RAISE NOTICE '--> stats_fn, _start_date [%], _end_date [%]', _start_date, _end_date;
1936+
-- Get global logs statistics
1937+
SELECT api.stats_logs_fn(_start_date::TEXT, _end_date::TEXT) INTO stats_logs;
1938+
-- Get global stays/moorages statistics
1939+
SELECT api.stats_stays_fn(_start_date::TEXT, _end_date::TEXT) INTO stats_moorages;
1940+
-- Get Top 5 trips statistics
1941+
WITH
1942+
logs_view AS (
1943+
SELECT id,avg_speed,max_speed,max_wind_speed,distance,duration
1944+
FROM api.logbook l
1945+
WHERE _from_time >= _start_date::TIMESTAMPTZ
1946+
AND _to_time <= _end_date::TIMESTAMPTZ + interval '23 hours 59 minutes'
1947+
),
1948+
logs_top_avg_speed AS (
1949+
SELECT id,avg_speed FROM logs_view
1950+
GROUP BY id,avg_speed
1951+
ORDER BY avg_speed DESC
1952+
LIMIT 5),
1953+
logs_top_speed AS (
1954+
SELECT id,max_speed FROM logs_view
1955+
WHERE max_speed IS NOT NULL
1956+
GROUP BY id,max_speed
1957+
ORDER BY max_speed DESC
1958+
LIMIT 5),
1959+
logs_top_wind_speed AS (
1960+
SELECT id,max_wind_speed FROM logs_view
1961+
WHERE max_wind_speed IS NOT NULL
1962+
GROUP BY id,max_wind_speed
1963+
ORDER BY max_wind_speed DESC
1964+
LIMIT 5),
1965+
logs_top_distance AS (
1966+
SELECT id FROM logs_view
1967+
GROUP BY id,distance
1968+
ORDER BY distance DESC
1969+
LIMIT 5),
1970+
logs_top_duration AS (
1971+
SELECT id FROM logs_view
1972+
GROUP BY id,duration
1973+
ORDER BY duration DESC
1974+
LIMIT 5)
1975+
-- Stats Top Logs
1976+
SELECT jsonb_build_object(
1977+
'stats_logs', stats_logs,
1978+
'stats_moorages', stats_moorages,
1979+
'logs_top_speed', (SELECT jsonb_agg(logs_top_speed.*) FROM logs_top_speed),
1980+
'logs_top_avg_speed', (SELECT jsonb_agg(logs_top_avg_speed.*) FROM logs_top_avg_speed),
1981+
'logs_top_wind_speed', (SELECT jsonb_agg(logs_top_wind_speed.*) FROM logs_top_wind_speed),
1982+
'logs_top_distance', (SELECT jsonb_agg(logs_top_distance.id) FROM logs_top_distance),
1983+
'logs_top_duration', (SELECT jsonb_agg(logs_top_duration.id) FROM logs_top_duration)
1984+
) INTO stats;
1985+
-- Stats top 5 moorages statistics
1986+
WITH
1987+
stays AS (
1988+
SELECT distinct(moorage_id) as moorage_id, sum(duration) as duration, count(id) as reference_count
1989+
FROM api.stays s
1990+
WHERE s.arrived >= _start_date::TIMESTAMPTZ
1991+
AND s.departed <= _end_date::TIMESTAMPTZ + interval '23 hours 59 minutes'
1992+
group by s.moorage_id
1993+
order by s.moorage_id
1994+
),
1995+
moorages AS (
1996+
SELECT m.id, m.home_flag, mv.stays_count, mv.stays_sum_duration, m.stay_code, m.country, s.duration as dur, s.reference_count as ref_count
1997+
FROM api.moorages m, stays s, api.moorage_view mv
1998+
WHERE s.moorage_id = m.id
1999+
AND mv.id = m.id
2000+
order by s.moorage_id
2001+
),
2002+
moorages_top_arrivals AS (
2003+
SELECT id,ref_count FROM moorages
2004+
GROUP BY id,ref_count
2005+
ORDER BY ref_count DESC
2006+
LIMIT 5),
2007+
moorages_top_duration AS (
2008+
SELECT id,dur FROM moorages
2009+
GROUP BY id,dur
2010+
ORDER BY dur DESC
2011+
LIMIT 5),
2012+
moorages_countries AS (
2013+
SELECT DISTINCT(country) FROM moorages
2014+
WHERE country IS NOT NULL AND country <> 'unknown'
2015+
GROUP BY country
2016+
ORDER BY country DESC
2017+
LIMIT 5)
2018+
SELECT stats || jsonb_build_object(
2019+
'moorages_top_arrivals', (SELECT jsonb_agg(moorages_top_arrivals) FROM moorages_top_arrivals),
2020+
'moorages_top_duration', (SELECT jsonb_agg(moorages_top_duration) FROM moorages_top_duration),
2021+
'moorages_top_countries', (SELECT jsonb_agg(moorages_countries.country) FROM moorages_countries)
2022+
) INTO stats;
2023+
END;
2024+
$function$
2025+
;
2026+
2027+
COMMENT ON FUNCTION api.stats_fn(in text, in text, out jsonb) IS 'Statistic by date for Logs and Moorages and Stays';
2028+
2029+
DROP VIEW IF EXISTS api.log_view;
2030+
-- Update log_view with dynamic GeoJSON
2031+
CREATE OR REPLACE VIEW api.log_view
2032+
WITH(security_invoker=true,security_barrier=true)
2033+
AS SELECT id,
2034+
name,
2035+
_from AS "from",
2036+
_from_time AS started,
2037+
_to AS "to",
2038+
_to_time AS ended,
2039+
distance,
2040+
duration,
2041+
notes,
2042+
api.export_logbook_geojson_trip_fn(id) AS geojson,
2043+
avg_speed,
2044+
max_speed,
2045+
max_wind_speed,
2046+
extra,
2047+
_from_moorage_id AS from_moorage_id,
2048+
_to_moorage_id AS to_moorage_id
2049+
FROM api.logbook l
2050+
WHERE _to_time IS NOT NULL
2051+
ORDER BY _from_time DESC;
2052+
-- Description
2053+
COMMENT ON VIEW api.log_view IS 'Log web view';
2054+
2055+
-- Update delete_trip_entry_fn, delete temporal sequence into a trip
2056+
CREATE OR REPLACE FUNCTION api.delete_trip_entry_fn(
2057+
_id INT,
2058+
update_string tstzspan -- tstzspan '[2024-11-07T18:40:45+00, 2024-11-07T18:41:45+00]'
2059+
)
2060+
RETURNS VOID AS $$
2061+
BEGIN
2062+
UPDATE api.logbook l
2063+
SET
2064+
trip = deleteTime(l.trip, update_string),
2065+
trip_cog = deleteTime(l.trip_cog, update_string),
2066+
trip_sog = deleteTime(l.trip_sog, update_string),
2067+
trip_twa = deleteTime(l.trip_twa, update_string),
2068+
trip_tws = deleteTime(l.trip_tws, update_string),
2069+
trip_twd = deleteTime(l.trip_twd, update_string),
2070+
trip_notes = deleteTime(l.trip_notes, update_string),
2071+
trip_status = deleteTime(l.trip_status, update_string),
2072+
trip_depth = deleteTime(l.trip_depth, update_string),
2073+
trip_batt_charge = deleteTime(l.trip_batt_charge, update_string),
2074+
trip_batt_voltage = deleteTime(l.trip_batt_voltage, update_string),
2075+
trip_temp_water = deleteTime(l.trip_temp_water, update_string),
2076+
trip_temp_out = deleteTime(l.trip_temp_out, update_string),
2077+
trip_pres_out = deleteTime(l.trip_pres_out, update_string),
2078+
trip_hum_out = deleteTime(l.trip_hum_out, update_string)
2079+
WHERE id = _id;
2080+
END;
2081+
$$ LANGUAGE plpgsql;
2082+
COMMENT ON FUNCTION api.delete_trip_entry_fn IS 'Delete at a specific time a temporal sequence for all trip_* column from a logbook';
2083+
18172084
-- Update api role SQL connection to 40
18182085
ALTER ROLE authenticator WITH NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOBYPASSRLS NOREPLICATION CONNECTION LIMIT 40 LOGIN;
18192086
ALTER ROLE api_anonymous WITH NOSUPERUSER NOCREATEDB NOCREATEROLE NOINHERIT NOBYPASSRLS NOREPLICATION CONNECTION LIMIT 40 LOGIN;
18202087

2088+
-- Allow users to update certain columns on specific TABLES on API schema
2089+
GRANT UPDATE (name, _from, _to, notes, trip_notes, trip, trip_cog, trip_sog, trip_twa, trip_tws, trip_twd, trip_status, trip_depth, trip_batt_charge, trip_batt_voltage, trip_temp_water, trip_temp_out, trip_pres_out, trip_hum_out) ON api.logbook TO user_role;
2090+
18212091
-- Refresh user_role permissions
18222092
GRANT SELECT ON TABLE api.log_view TO api_anonymous;
18232093
GRANT EXECUTE ON FUNCTION api.export_logbooks_geojson_linestring_trips_fn to api_anonymous;
18242094
GRANT EXECUTE ON FUNCTION api.export_logbooks_geojson_point_trips_fn to api_anonymous;
1825-
GRANT EXECUTE ON FUNCTION api.logbook_update_geojson_trip_fn to api_anonymous;
2095+
--GRANT EXECUTE ON FUNCTION api.logbook_update_geojson_trip_fn to api_anonymous;
18262096
GRANT EXECUTE ON FUNCTION api.export_logbook_geojson_trip_fn to api_anonymous;
18272097
GRANT EXECUTE ON ALL FUNCTIONS IN SCHEMA public TO api_anonymous;
18282098
GRANT SELECT ON TABLE api.moorage_view TO grafana;

0 commit comments

Comments
 (0)