added support for multiple accounts

This commit is contained in:
Peter Wood
2023-03-04 21:10:46 -05:00
parent e88dffe457
commit 098ea60ef0
5 changed files with 71 additions and 61 deletions

View File

@@ -1,6 +1,7 @@
create or replace procedure import_budget_from_csv()
create or replace procedure public.import_budget_from_csv()
language plpgsql
as $procedure$
as $$
begin
truncate table public.budgetimport;
@@ -9,10 +10,10 @@ copy
public.budgetimport(dt, amount, description)
from
'/usr/share/budget.csv'
delimiter ','
csv
header;
commit;
end;
$procedure$;
delimiter ',' csv header;
end
$$;
GRANT EXECUTE ON PROCEDURE public.update_budget_from_import() TO acedanger;
GRANT EXECUTE ON PROCEDURE public.update_budget_from_import() TO budgetuser;

View File

@@ -1,4 +1,4 @@
drop table if exists public.accounts;
drop table if exists public.accounts cascade;
CREATE TABLE public.accounts(
acct_id serial,
@@ -6,14 +6,20 @@ CREATE TABLE public.accounts(
account_type varchar(50) not null,
account_number varchar(20) null,
friendly_name varchar(50) null,
insert_dt_tm timestamp default now(),
insert_dt_tm timestamp null default now(),
PRIMARY KEY( acct_id )
);
INSERT INTO public.accounts (bank_name, account_type, friendly_name) values
('Bank of America', 'Checking', 'Joint Checking')
, ('Ally', 'Savings', 'Joint Savings')
, ('Ally', 'Savings', 'Vacation Savings')
-- Permissions
select * from public.accounts a
ALTER TABLE public.accounts OWNER TO acedanger;
GRANT ALL ON TABLE public.accounts TO acedanger;
GRANT ALL ON TABLE public.accounts TO budgetuser;
-- Populate table
truncate public.accounts;
INSERT INTO public.accounts (bank_name, account_type, friendly_name, account_number) values
('Bank of America', 'Checking', 'Joint Checking', '4581')
, ('Ally', 'Savings', 'Joint Savings', '9969')
, ('Ally', 'Savings', 'Vacation Savings', '6268')

View File

@@ -1,15 +1,17 @@
-- public.budgetdetails definition
-- Drop table
DROP TABLE public.budgetdetails;
DROP table if exists public.budgetdetails cascade;
CREATE TABLE public.budgetdetails (
trxid uuid NOT NULL DEFAULT uuid_generate_v4(),
trxdescription text NOT NULL,
trxdate date NOT NULL,
trxamount money NOT NULL,
insertdttm timestamp NULL DEFAULT now(),
CONSTRAINT budgetdetails_pkey PRIMARY KEY (trxid)
trx_id uuid NOT NULL DEFAULT uuid_generate_v4(),
trx_description text NOT NULL,
trx_date date NOT NULL,
trx_amount numeric NOT NULL,
acct_id int NULL,
insert_dt_tm timestamp NULL DEFAULT now(),
primary key ( trx_id ),
constraint fk_acct foreign key ( acct_id ) references public.accounts(acct_id) on delete set null
);
-- Permissions

View File

@@ -1,46 +1,44 @@
/*
truncate table budgetdetails;
CALL public.import_budget_from_csv();
CALL public.update_budget_from_import();
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
lower(trxdescription) trxdescription
, avg(abs(trxamount)) avg_amt
, min(abs(trxamount)) min_amt
, max(abs(trxamount)) max_amt
, count(trxdescription) rec_cnt
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
from
public.budgetdetails b
where
trxdate <= current_date
and abs(trxamount) > 0
trx_date <= current_date
and abs(trx_amount) > 0
group by
lower(trxdescription)
lower(trx_description)
having
count(1) > 2
order by
rec_cnt desc
, trxdescription;
, trx_description;
select
bal.trxdate
bal.trx_date
, bal.day_of_week
, age(trxdate, current_date) as days_from_today
, bal.trxdescription
, bal.trxamount
, bal.runningbal
, age(trx_date, current_date) as days_from_today
, bal.trx_description
, bal.trx_amount
, bal.running_bal
from
public.runbal bal
where
trxdate between current_date and (
current_date + interval '2 weeks'
trx_date between current_date and (
current_date + interval '3 weeks'
)::date
;
select * from budgetimport b
where dt like '2023-03%'

View File

@@ -1,18 +1,21 @@
drop view public.runbal;
drop view if exists public.runbal;
create view public.runbal
as
select
trxdate
, trxdescription
, trxamount
, to_char(trxdate, 'day') day_of_week
, sum(trxamount) over(
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
trxdate
, trxamount desc rows unbounded preceding
) runningbal
det.trx_date
, det.trx_amount desc rows unbounded preceding
) running_bal
from
public.budgetdetails
public.budgetdetails det
join public.accounts acct using (acct_id)