diff --git a/postgres/functions/get_aggregated_account_transactions b/postgres/functions/get_aggregated_account_transactions new file mode 100644 index 0000000..f41700c --- /dev/null +++ b/postgres/functions/get_aggregated_account_transactions @@ -0,0 +1,39 @@ +-- DROP FUNCTION public.get_transactions_for_period(text, date, date); + +CREATE OR REPLACE FUNCTION public.get_transactions_for_period(p_account_name text, p_start date DEFAULT NULL::date, p_end date DEFAULT NULL::date) + RETURNS TABLE(bank_name text, account_type text, account_number text, account_friendly_name text, transaction_date date, transaction_description text, transaction_amount numeric, transaction_day_of_week text, running_bal numeric) + LANGUAGE plpgsql +AS $function$ +DECLARE + v_start_date date; + v_end_date date; + +begin + -- Set default values for start and end dates if not provided by the caller + IF p_start IS NULL THEN + v_start_date := make_date(date_part('year', now())::int, 1, 1); + ELSE + v_start_date := p_start; + END IF; + + IF p_end IS NULL THEN + v_end_date := (SELECT (date_trunc('month', NOW()) + interval '1 month - 1 day')::date); + ELSE + v_end_date := p_end; + END IF; +raise notice 'FUNCTION: get_transactions_for_period'; +-- E'\n' is new line +raise notice 'INPUT: % v_start_date = %; % v_end_date = %;', E'\n', v_start_date, E'\n', v_end_date; + +return query + select + bl.account_bank_name, bl.account_type, bl.account_number, bl.account_friendly_name + , bl.transaction_date, bl.transaction_description, bl.transaction_amount + , bl.transaction_day_of_week, bl.running_bal + from public.runbal bl + where + lower(bl.account_friendly_name) = trim(lower(p_account_name)) + and bl.transaction_date between v_start_date and v_end_date; +end; +$function$ +;