From bed53d0a2f1438515d21ce9b0a41be31a338146f Mon Sep 17 00:00:00 2001 From: Kevin Cantrell Date: Wed, 19 Nov 2025 14:48:18 +0900 Subject: [PATCH] moving to a new version of the report function because the oldone is cached??? --- ..._filtered_device_report_data_multi_v2.sql} | 6 +- database.types.ts | 2 +- src/lib/services/DeviceDataService.ts | 2 +- src/lib/tests/ReportTimezone.test.ts | 4 +- ...0221120000_update_report_proc_timezone.sql | 4 +- .../20250224120000_create_report_proc_v2.sql | 133 ++++++++++++++++++ 6 files changed, 142 insertions(+), 9 deletions(-) rename SUPABASE_STORED_PROCS/{get_filtered_device_report_data_multi.sql => get_filtered_device_report_data_multi_v2.sql} (98%) create mode 100644 supabase/migrations/20250224120000_create_report_proc_v2.sql diff --git a/SUPABASE_STORED_PROCS/get_filtered_device_report_data_multi.sql b/SUPABASE_STORED_PROCS/get_filtered_device_report_data_multi_v2.sql similarity index 98% rename from SUPABASE_STORED_PROCS/get_filtered_device_report_data_multi.sql rename to SUPABASE_STORED_PROCS/get_filtered_device_report_data_multi_v2.sql index 88341269..78dffbdc 100644 --- a/SUPABASE_STORED_PROCS/get_filtered_device_report_data_multi.sql +++ b/SUPABASE_STORED_PROCS/get_filtered_device_report_data_multi_v2.sql @@ -1,5 +1,5 @@ -- 1) Create the function -CREATE OR REPLACE FUNCTION get_filtered_device_report_data_multi( +CREATE OR REPLACE FUNCTION get_filtered_device_report_data_multi_v2( p_dev_id TEXT, p_start_time TIMESTAMPTZ, p_end_time TIMESTAMPTZ, @@ -106,7 +106,7 @@ BEGIN dedup AS ( SELECT DISTINCT ON (bucket) %s FROM sampled - ORDER BY bucket, created_at + ORDER BY bucket, created_at DESC ), exceptions AS ( SELECT %s @@ -133,4 +133,4 @@ BEGIN RETURN QUERY EXECUTE sql; END; -$function$; \ No newline at end of file +$function$; diff --git a/database.types.ts b/database.types.ts index 2dcdf7e6..30085668 100644 --- a/database.types.ts +++ b/database.types.ts @@ -1925,7 +1925,7 @@ export type Database = { Args: { bucket: string; object: string }; Returns: Record; }; - get_filtered_device_report_data_multi: { + get_filtered_device_report_data_multi_v2: { Args: { p_columns: string[]; p_dev_id: string; diff --git a/src/lib/services/DeviceDataService.ts b/src/lib/services/DeviceDataService.ts index 203f69ad..fdbb3fc7 100644 --- a/src/lib/services/DeviceDataService.ts +++ b/src/lib/services/DeviceDataService.ts @@ -399,7 +399,7 @@ export class DeviceDataService implements IDeviceDataService { // } const { data, error: deviceError } = await this.supabase.rpc( - 'get_filtered_device_report_data_multi', + 'get_filtered_device_report_data_multi_v2', { p_dev_id: devEui, p_start_time: startDate, diff --git a/src/lib/tests/ReportTimezone.test.ts b/src/lib/tests/ReportTimezone.test.ts index e0ba785a..1dc19db7 100644 --- a/src/lib/tests/ReportTimezone.test.ts +++ b/src/lib/tests/ReportTimezone.test.ts @@ -76,7 +76,7 @@ describe('Report Data Timezone Tests', () => { // Assert expect(mockSupabase.rpc).toHaveBeenCalledWith( - 'get_filtered_device_report_data_multi', + 'get_filtered_device_report_data_multi_v2', expect.objectContaining({ p_dev_id: '110110145241600107', p_start_time: startDate, @@ -181,7 +181,7 @@ describe('Report Data Timezone Tests', () => { // Assert expect(mockSupabase.rpc).toHaveBeenCalledWith( - 'get_filtered_device_report_data_multi', + 'get_filtered_device_report_data_multi_v2', expect.objectContaining({ p_columns: ['temperature_c', 'humidity'], p_ops: ['>', 'BETWEEN'], diff --git a/supabase/migrations/20250221120000_update_report_proc_timezone.sql b/supabase/migrations/20250221120000_update_report_proc_timezone.sql index 88341269..055ba718 100644 --- a/supabase/migrations/20250221120000_update_report_proc_timezone.sql +++ b/supabase/migrations/20250221120000_update_report_proc_timezone.sql @@ -106,7 +106,7 @@ BEGIN dedup AS ( SELECT DISTINCT ON (bucket) %s FROM sampled - ORDER BY bucket, created_at + ORDER BY bucket, created_at DESC ), exceptions AS ( SELECT %s @@ -133,4 +133,4 @@ BEGIN RETURN QUERY EXECUTE sql; END; -$function$; \ No newline at end of file +$function$; diff --git a/supabase/migrations/20250224120000_create_report_proc_v2.sql b/supabase/migrations/20250224120000_create_report_proc_v2.sql new file mode 100644 index 00000000..87236bd2 --- /dev/null +++ b/supabase/migrations/20250224120000_create_report_proc_v2.sql @@ -0,0 +1,133 @@ +DROP FUNCTION IF EXISTS public.get_filtered_device_report_data_multi_v2( + TEXT, TIMESTAMPTZ, TIMESTAMPTZ, INTEGER, TEXT[], TEXT[], DOUBLE PRECISION[], DOUBLE PRECISION[], TEXT +); + +CREATE OR REPLACE FUNCTION get_filtered_device_report_data_multi_v2( + p_dev_id TEXT, + p_start_time TIMESTAMPTZ, + p_end_time TIMESTAMPTZ, + p_interval_minutes INTEGER, + p_columns TEXT[], + p_ops TEXT[], + p_mins DOUBLE PRECISION[], + p_maxs DOUBLE PRECISION[], + p_timezone TEXT DEFAULT 'UTC' +) +RETURNS SETOF JSONB +LANGUAGE plpgsql +AS $function$ +DECLARE + v_target_table TEXT; + candidate_cols TEXT[]; + final_cols TEXT[] := ARRAY[]::TEXT[]; + col TEXT; + has_nonnull BOOLEAN; + column_list TEXT; + i INT; + cond_clauses TEXT[] := ARRAY[]::TEXT[]; + exceptions_where TEXT; + sql TEXT; + excluded_cols TEXT[] := ARRAY[ + 'dev_eui','smoke_detected','vape_detected','battery_level','is_simulated' + ]; +BEGIN + PERFORM set_config('TimeZone', COALESCE(NULLIF(p_timezone, ''), 'UTC'), true); + + SELECT cdt.data_table_v2 + INTO v_target_table + FROM cw_devices dev + JOIN cw_device_type cdt ON dev."type" = cdt.id + WHERE dev.dev_eui = p_dev_id; + IF v_target_table IS NULL THEN + RAISE EXCEPTION 'No data table for dev_eui=%', p_dev_id; + END IF; + + SELECT array_agg(column_name) + INTO candidate_cols + FROM information_schema.columns + WHERE table_schema = 'public' + AND table_name = v_target_table + AND column_name <> ALL(excluded_cols); + IF candidate_cols IS NULL THEN + RAISE EXCEPTION 'No columns in %', v_target_table; + END IF; + + FOREACH col IN ARRAY candidate_cols LOOP + EXECUTE format( + 'SELECT EXISTS(SELECT 1 FROM %I WHERE dev_eui = %L AND created_at BETWEEN %L AND %L AND %I IS NOT NULL)', + v_target_table, p_dev_id, p_start_time, p_end_time, col + ) INTO has_nonnull; + IF has_nonnull THEN + final_cols := final_cols || quote_ident(col); + END IF; + END LOOP; + IF array_length(final_cols,1) IS NULL THEN + RAISE EXCEPTION 'No populated columns in %', v_target_table; + END IF; + column_list := array_to_string(final_cols, ', '); + + IF NOT ( + array_length(p_columns,1) = array_length(p_ops,1) + AND array_length(p_columns,1) = array_length(p_mins,1) + AND array_length(p_columns,1) = array_length(p_maxs,1) + ) THEN + RAISE EXCEPTION 'Array lengths for columns/ops/mins/maxs must match'; + END IF; + + FOR i IN 1 .. array_length(p_columns,1) LOOP + IF p_ops[i] ILIKE 'between' AND p_maxs[i] IS NOT NULL THEN + cond_clauses := cond_clauses || + format('%I BETWEEN %L AND %L', p_columns[i], p_mins[i], p_maxs[i]); + ELSE + cond_clauses := cond_clauses || + format('%I %s %L', p_columns[i], p_ops[i], p_mins[i]); + END IF; + END LOOP; + exceptions_where := array_to_string(cond_clauses, ' OR '); + + sql := format($query$ + WITH filtered AS ( + SELECT %s + FROM %I + WHERE dev_eui = %L + AND created_at BETWEEN %L AND %L + ), + sampled AS ( + SELECT *, + FLOOR( + EXTRACT(EPOCH FROM created_at - %L::timestamptz) + / (%s * 60) + ) AS bucket + FROM filtered + ), + dedup AS ( + SELECT DISTINCT ON (bucket) %s + FROM sampled + ORDER BY bucket, created_at DESC + ), + exceptions AS ( + SELECT %s + FROM filtered + WHERE %s + ) + SELECT to_jsonb(x) + FROM ( + SELECT * FROM dedup + UNION + SELECT * FROM exceptions + ) x + ORDER BY created_at + $query$, + column_list, + v_target_table, + p_dev_id, p_start_time, p_end_time, + p_start_time, + p_interval_minutes, + column_list, + column_list, + exceptions_where + ); + + RETURN QUERY EXECUTE sql; +END; +$function$;