added support for multiple accounts in the budget detail table

This commit is contained in:
Peter Wood
2023-03-06 11:58:49 -05:00
parent f07d5a4c7c
commit 1214176dba
3 changed files with 42 additions and 15 deletions

View File

@@ -1,9 +1,25 @@
create or replace procedure public.import_budget_from_csv()
create or replace procedure public.import_transactions_from_csv(
p_bank_name varchar
, p_bank_account_number varchar
)
language plpgsql
as $$
declare
_acct int;
begin
raise notice 'PROC: import_transactions_from_csv';
raise notice 'INPUT: % p_bank_name = %; % p_bank_account_number = %;', E'\n', p_bank_name, E'\n', p_bank_account_number;
_acct := public.get_account_id(p_bank_name, p_bank_account_number);
if _acct is null then
raise exception 'could not get the account id for bank_name (%) and bank account number (%)', p_bank_name, p_bank_account_number;
end if;
truncate table public.budgetimport;
copy
@@ -12,8 +28,17 @@ from
'/usr/share/budget.csv'
delimiter ',' csv header;
delete from public.budgetdetails where acct_id = _acct;
insert into public.budgetdetails (trx_description, trx_date, trx_amount, acct_id)
select
description
, cast(dt as date) as dt_converted
, amount
, _acct
from public.budgetimport;
end
$$;
GRANT EXECUTE ON PROCEDURE public.update_budget_from_import() TO acedanger;
GRANT EXECUTE ON PROCEDURE public.update_budget_from_import() TO budgetuser;
GRANT EXECUTE ON PROCEDURE public.import_transactions_from_csv(varchar, varchar) TO acedanger;
GRANT EXECUTE ON PROCEDURE public.import_transactions_from_csv(varchar, varchar) TO budgetuser;

View File

@@ -1,7 +1,7 @@
DROP TABLE public.budgetimport;
create table public.budgetimport (
dt bpchar(10) NULL,
dt bpchar(20) NULL,
amount numeric(10, 2) NULL,
description bpchar(200) NULL
);

View File

@@ -3,19 +3,21 @@ drop view if exists public.runbal;
create view public.runbal
as
select
acct.bank_name
acct.bank_name
, acct.account_type
, acct.account_number
, acct.friendly_name
, det.trx_date
, det.trx_description
, det.trx_amount::numeric(8,2)
, to_char(det.trx_date, 'day') day_of_week
, sum(det.trx_amount) over(
order by
det.trx_date
, det.trx_amount desc rows unbounded preceding
) running_bal
, trx.trx_date
, trx.trx_description
, trx.trx_amount::numeric(8,2)
, to_char(trx.trx_date, 'day') day_of_week
, sum(trx.trx_amount)
over(
partition by trx.acct_id
order by
trx.trx_date
, trx.trx_amount desc rows unbounded preceding
) running_bal
from
public.budgetdetails det
public.budgetdetails trx
join public.accounts acct using (acct_id)