Skip to content

Commit

Permalink
feat: add daily rain tables (#268)
Browse files Browse the repository at this point in the history
* feat: add monthly rain tables

* fix: foreign key

* fix: daily weather data

* fix: add RLS

* feat: created_at column, just to be sure

* feat: function for fetching aggregated weather data

* chore: formatting

* feat: add parameter to limit number of returned months

* fix: typo
  • Loading branch information
Jaszkowic committed Jun 20, 2024
1 parent 70155fd commit d8ab5c5
Show file tree
Hide file tree
Showing 2 changed files with 57 additions and 0 deletions.
25 changes: 25 additions & 0 deletions supabase/migrations/20240619130511_montly_rain.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,25 @@
create table if not exists daily_weather_data (
id serial primary key,
created_at timestamp not null default now(),
measure_day timestamp not null,
day_finished boolean not null default false,
sum_precipitation_mm_per_sqm float,
avg_temperature_celsius float,
avg_pressure_msl float,
sum_sunshine_minutes float,
avg_wind_direction_deg float,
avg_wind_speed_kmh float,
avg_cloud_cover_percentage float,
avg_dew_point_celcius float,
avg_relative_humidity_percentage float,
avg_visibility_m float,
avg_wind_gust_direction_deg float,
avg_wind_gust_speed_kmh float,
source_dwd_station_ids text[]
);

alter table "public"."daily_weather_data" enable row level security;
create policy "Allow anonymous select on daily_weather_data"
on "public"."daily_weather_data"
for select
using (true);
32 changes: 32 additions & 0 deletions supabase/migrations/20240620113031_rain_functions.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,32 @@
CREATE OR REPLACE FUNCTION public.accumulated_weather_per_month (limit_monts int)
RETURNS TABLE (
measure_day text, sum_precipitation_mm_per_sqm float, avg_temperature_celsius float, avg_pressure_msl float, sum_sunshine_minutes float, avg_wind_direction_deg float, avg_wind_speed_kmh float, avg_cloud_cover_percentage float, avg_dew_point_celcius float, avg_relative_humidity_percentage float, avg_visibility_m float, avg_wind_gust_direction_deg float, avg_wind_gust_speed_kmh float)
LANGUAGE plpgsql
SECURITY INVOKER
AS $function$
BEGIN
RETURN query
SELECT
to_char(daily_weather_data.measure_day, 'YYYY-MM'),
sum(daily_weather_data.sum_precipitation_mm_per_sqm) AS sum_precipitation_mm_per_sqm,
avg(daily_weather_data.avg_temperature_celsius) AS avg_temperature_celsius,
avg(daily_weather_data.avg_pressure_msl) AS avg_pressure_msl,
sum(daily_weather_data.sum_sunshine_minutes) AS sum_sunshine_minutes,
avg(daily_weather_data.avg_wind_direction_deg) AS avg_wind_direction_deg,
avg(daily_weather_data.avg_wind_speed_kmh) AS avg_wind_speed_kmh,
avg(daily_weather_data.avg_cloud_cover_percentage) AS avg_cloud_cover_percentage,
avg(daily_weather_data.avg_dew_point_celcius) AS avg_dew_point_celcius,
avg(daily_weather_data.avg_relative_humidity_percentage) AS avg_relative_humidity_percentage,
avg(daily_weather_data.avg_visibility_m) AS avg_visibility_m,
avg(daily_weather_data.avg_wind_gust_direction_deg) AS avg_wind_gust_direction_deg,
avg(daily_weather_data.avg_wind_gust_speed_kmh) AS avg_wind_gust_speed_kmh
FROM
daily_weather_data
GROUP BY
to_char(daily_weather_data.measure_day, 'YYYY-MM')
ORDER BY
to_char(daily_weather_data.measure_day, 'YYYY-MM')
DESC
LIMIT limit_monts;
END;
$function$;

0 comments on commit d8ab5c5

Please sign in to comment.