added function to get transactions for a period of time

This commit is contained in:
Peter Wood
2023-03-09 20:02:01 -05:00
parent 1214176dba
commit a63a2cf8f4
2 changed files with 76 additions and 19 deletions

View File

@@ -0,0 +1,43 @@
drop function if exists public.get_transactions_for_period;
create or replace function public.get_transactions_for_period(
p_account_name text
, p_start date
, p_end 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(8,2)
, transaction_day_of_week text
, running_bal numeric
)
LANGUAGE plpgsql
AS $$
begin
raise notice 'FUNCTION: get_transactions';
-- E'\n' is new line
raise notice 'INPUT: % p_start = %; % p_end = %;', E'\n', p_start, E'\n', p_end;
return query
select
bl.bank_name, bl.account_type, bl.account_number, bl.friendly_name as account_friendly_name
, bl.trx_date as transaction_date, bl.trx_description as transaction_description, bl.trx_amount as transaction_amount
, bl.day_of_week as transaction_day_of_week, bl.running_bal
from public.runbal bl
where
lower(bl.friendly_name) = trim(lower(p_account_name))
and bl.trx_date between p_start and p_end;
end;
$$;
GRANT EXECUTE ON function public.get_transactions_for_period(text, date, date) TO acedanger;
GRANT EXECUTE ON function public.get_transactions_for_period(text, date, date) TO budgetuser;

View File

@@ -1,39 +1,47 @@
select get_account_id('Bank of America', '4581')
CALL public.import_budget_from_csv();
CALL public.update_budget_from_import('bank of america', '4581');
select 'Import' as TBL, count(1) as REC_CNT from public.budgetimport
union all
select 'Detail' as TBL, count(1) as REC_CNT from public.budgetdetails;
select acct_id, count(1)
from public.budgetdetails b
group by acct_id
select acct.friendly_name, count(1) as "Number of Transactions"
from
public.budgetdetails trx
inner join public.accounts acct using(acct_id)
group by acct.friendly_name
select
lower(trx_description) trx_description
, avg(abs(trx_amount))::numeric(7,2) avg_amt
, count(trx_description) rec_cnt
, min(abs(trx_amount))::numeric(7,2) min_amt
, max(abs(trx_amount))::numeric(7,2) max_amt
acct.friendly_name
, extract(year from trx.trx_date) trx_year
, lower(trx.trx_description) trx_description
, avg(abs(trx.trx_amount))::numeric(7,2) avg_amt
, count(trx.trx_description) rec_cnt
, min(abs(trx.trx_amount))::numeric(7,2) min_amt
, max(abs(trx.trx_amount))::numeric(7,2) max_amt
, sum(abs(trx.trx_amount))::numeric(9,2) ttl_amt
from
public.budgetdetails b
public.budgetdetails trx
inner join public.accounts acct using(acct_id)
where
trx_date <= current_date
and abs(trx_amount) > 0
trx.trx_date <= current_date
and abs(trx.trx_amount) > 0
-- and lower(acct.friendly_name) like '%savings'
group by
lower(trx_description)
trx_year, acct.friendly_name, lower(trx_description)
having
count(1) > 2
order by
rec_cnt desc
, trx_description;
trx_year desc
, acct.friendly_name
, rec_cnt desc
, lower(trx.trx_description);
select
bal.trx_date
bal.friendly_name
, bal.trx_date
, bal.day_of_week
, age(trx_date, current_date) as days_from_today
, bal.trx_description
@@ -42,9 +50,15 @@ select
from
public.runbal bal
where
trx_date between current_date and (
lower(account_type) = 'checking'
and trx_date between
(current_date - interval '1 week')
and (
current_date + interval '3 weeks'
)::date
;
select *
from public.get_transactions_for_period('joint checking', '3/1/2023'::date, '3/31/2023'::date)