Skip to content

Commit

Permalink
feat: more database functions
Browse files Browse the repository at this point in the history
  • Loading branch information
Jaszkowic committed Jul 2, 2024
1 parent 9bf337b commit 57445ce
Show file tree
Hide file tree
Showing 3 changed files with 197 additions and 7 deletions.
95 changes: 95 additions & 0 deletions src/database.ts
Original file line number Diff line number Diff line change
Expand Up @@ -51,6 +51,66 @@ export type Database = {
},
]
}
daily_weather_data: {
Row: {
avg_cloud_cover_percentage: number | null
avg_dew_point_celcius: number | null
avg_pressure_msl: number | null
avg_relative_humidity_percentage: number | null
avg_temperature_celsius: number | null
avg_visibility_m: number | null
avg_wind_direction_deg: number | null
avg_wind_gust_direction_deg: number | null
avg_wind_gust_speed_kmh: number | null
avg_wind_speed_kmh: number | null
created_at: string
day_finished: boolean
id: number
measure_day: string
source_dwd_station_ids: string[] | null
sum_precipitation_mm_per_sqm: number | null
sum_sunshine_minutes: number | null
}
Insert: {
avg_cloud_cover_percentage?: number | null
avg_dew_point_celcius?: number | null
avg_pressure_msl?: number | null
avg_relative_humidity_percentage?: number | null
avg_temperature_celsius?: number | null
avg_visibility_m?: number | null
avg_wind_direction_deg?: number | null
avg_wind_gust_direction_deg?: number | null
avg_wind_gust_speed_kmh?: number | null
avg_wind_speed_kmh?: number | null
created_at?: string
day_finished?: boolean
id?: number
measure_day: string
source_dwd_station_ids?: string[] | null
sum_precipitation_mm_per_sqm?: number | null
sum_sunshine_minutes?: number | null
}
Update: {
avg_cloud_cover_percentage?: number | null
avg_dew_point_celcius?: number | null
avg_pressure_msl?: number | null
avg_relative_humidity_percentage?: number | null
avg_temperature_celsius?: number | null
avg_visibility_m?: number | null
avg_wind_direction_deg?: number | null
avg_wind_gust_direction_deg?: number | null
avg_wind_gust_speed_kmh?: number | null
avg_wind_speed_kmh?: number | null
created_at?: string
day_finished?: boolean
id?: number
measure_day?: string
source_dwd_station_ids?: string[] | null
sum_precipitation_mm_per_sqm?: number | null
sum_sunshine_minutes?: number | null
}
Relationships: []
}
profiles: {
Row: {
id: string
Expand Down Expand Up @@ -311,6 +371,41 @@ export type Database = {
[_ in never]: never
}
Functions: {
accumulated_weather_per_month: {
Args: {
limit_monts: number
}
Returns: {
measure_day: string
sum_precipitation_mm_per_sqm: number
avg_temperature_celsius: number
avg_pressure_msl: number
sum_sunshine_minutes: number
avg_wind_direction_deg: number
avg_wind_speed_kmh: number
avg_cloud_cover_percentage: number
avg_dew_point_celcius: number
avg_relative_humidity_percentage: number
avg_visibility_m: number
avg_wind_gust_direction_deg: number
avg_wind_gust_speed_kmh: number
}[]
}
calculate_avg_waterings_per_month: {
Args: Record<PropertyKey, never>
Returns: {
month: string
watering_count: number
avg_amount_per_watering: number
}[]
}
calculate_top_tree_species: {
Args: Record<PropertyKey, never>
Returns: {
gattung_deutsch: string
percentage: number
}[]
}
count_by_age: {
Args: {
start_year: number
Expand Down
63 changes: 57 additions & 6 deletions supabase/functions/gdk_stats/index.ts
Original file line number Diff line number Diff line change
@@ -1,10 +1,12 @@
import { createClient } from "https://esm.sh/@supabase/supabase-js@2";
import { corsHeaders } from "../_shared/cors.ts";

const SUPABASE_URL = Deno.env.get("SUPABASE_URL");
const SUPABASE_SERVICE_ROLE_KEY = Deno.env.get("SUPABASE_SERVICE_ROLE_KEY");
const SUPABASE_URL = Deno.env.get("URL");
const SUPABASE_SERVICE_ROLE_KEY = Deno.env.get("SERVICE_ROLE_KEY");
const PUMPS_URL = Deno.env.get("PUMPS_URL");

console.log(SUPABASE_URL, SUPABASE_SERVICE_ROLE_KEY, PUMPS_URL);

interface TreeSpecies {
speciesName?: string;
percentage: number;
Expand All @@ -14,6 +16,20 @@ interface Monthly {
month: string;
wateringCount: number;
averageAmountPerWatering: number;
totalSum: number;
}

interface Watering {
id: string;
lat: number;
lng: number;
amount: number;
timestamp: string;
}

interface TreeAdoptions {
count: number;
veryThirstyCount: number;
}

interface GdkStats {
Expand All @@ -22,8 +38,9 @@ interface GdkStats {
numActiveUsers: number;
numWateringsThisYear: number;
monthlyWaterings: Monthly[];
numTreeAdoptions: number;
treeAdoptions: TreeAdoptions;
mostFrequentTreeSpecies: TreeSpecies[];
waterings: Watering[];
}

// As trees table barely changes, we can hardcode the values
Expand Down Expand Up @@ -87,17 +104,48 @@ const getPumpsCount = async (): Promise<number> => {
return geojson.features.length;
};

const getAdoptedTreesCount = async (): Promise<TreeAdoptions> => {
const { data, error } = await supabaseServiceRoleClient
.rpc("calculate_adoptions")
.select("*");

return {
count: data[0].total_adoptions,
veryThirstyCount: data[0].very_thirsty_adoptions,
} as TreeAdoptions;
};

const getMonthlyWaterings = async (): Promise<Monthly[]> => {
const { data, error } = await supabaseServiceRoleClient
.rpc("calculate_avg_waterings_per_month")
.select("*");

return data.map((month: any) => ({
month: month.month,
wateringCount: month.watering_count,
totalSum: month.total_sum,
averageAmountPerWatering: month.avg_amount_per_watering,
}));
};

const getWaterings = async (): Promise<Watering[]> => {
const { data, error } = await supabaseServiceRoleClient
.rpc("get_waterings_with_location")
.select("*");

console.log(data, JSON.stringify(error));

return data.map((watering: any) => {
return {
id: watering.id,
lat: watering.lat,
lng: watering.lng,
amount: watering.amount,
timestamp: watering.timestamp,
};
});
};

const handler = async (request: Request): Promise<Response> => {
if (request.method === "OPTIONS") {
return new Response(null, { headers: corsHeaders, status: 204 });
Expand All @@ -107,15 +155,17 @@ const handler = async (request: Request): Promise<Response> => {
const [
usersCount,
wateringsCount,
adoptionsCount,
treeAdoptions,
numPumps,
monthlyWaterings,
waterings,
] = await Promise.all([
getCount("profiles"),
getWateringsCount(),
getCount("trees_adopted"),
getAdoptedTreesCount(),
getPumpsCount(),
getMonthlyWaterings(),
getWaterings(),
]);

const stats: GdkStats = {
Expand All @@ -124,8 +174,9 @@ const handler = async (request: Request): Promise<Response> => {
numActiveUsers: usersCount,
numWateringsThisYear: wateringsCount,
monthlyWaterings: monthlyWaterings,
numTreeAdoptions: adoptionsCount,
treeAdoptions: treeAdoptions,
mostFrequentTreeSpecies: MOST_FREQUENT_TREE_SPECIES,
waterings: waterings,
};

return new Response(JSON.stringify(stats), {
Expand Down
46 changes: 45 additions & 1 deletion supabase/migrations/20240620143046_db_stats_functions.sql
Original file line number Diff line number Diff line change
Expand Up @@ -23,4 +23,48 @@ BEGIN
ORDER BY COUNT(1) DESC
LIMIT 20;
END;
$function$;
$function$;

CREATE OR REPLACE FUNCTION public.get_waterings_with_location()
RETURNS TABLE(id text, lat double precision, lng double precision, amount numeric, "timestamp" timestamp with time zone)
LANGUAGE plpgsql
AS $function$
BEGIN
RETURN QUERY
SELECT t.id, ST_Y(t.geom) AS lat, ST_X(t.geom) AS lng, tw.amount, tw."timestamp"
from trees_watered tw, trees t
where tw.tree_id = t.id
and tw."timestamp" > DATE_TRUNC('year', CURRENT_DATE)::date;
END;
$function$;

CREATE OR REPLACE FUNCTION public.calculate_adoptions()
RETURNS TABLE(total_adoptions bigint, very_thirsty_adoptions bigint)
LANGUAGE plpgsql
AS $function$
BEGIN
RETURN QUERY
WITH adoptions AS (
SELECT
ta.id AS adoption_id,
t.id AS tree_id,
t.pflanzjahr,
date_part('year',
now()) - t.pflanzjahr AS age,
(date_part('year',
now()) - t.pflanzjahr >= 5
AND date_part('year',
now()) - t.pflanzjahr <= 10) AS very_thirsty
FROM
trees_adopted ta,
trees t
WHERE
ta.tree_id = t.id
)
SELECT
count(1) total_adoptions,
count(1) FILTER (WHERE adoptions.very_thirsty) AS very_thirsty_adoptions
FROM
adoptions;
END;
$function$

0 comments on commit 57445ce

Please sign in to comment.