From 64822912d9f3205a130ef9c207233e593746f9d6 Mon Sep 17 00:00:00 2001 From: Jan Bader Date: Tue, 7 Dec 2021 20:22:40 +0000 Subject: [PATCH] Add available balance --- http/budgeting.go | 16 ++++++-- postgres/budgets.sql.go | 27 +++++++++++--- postgres/categories.sql.go | 37 ++++++++++++++++++- postgres/models.go | 1 + postgres/queries/categories.sql | 29 ++++++++++++++- .../schema/202112072032_income-category.sql | 14 +++++++ web/budgeting.html | 5 +++ 7 files changed, 116 insertions(+), 13 deletions(-) create mode 100644 postgres/schema/202112072032_income-category.sql diff --git a/http/budgeting.go b/http/budgeting.go index 7d5983c..9c46969 100644 --- a/http/budgeting.go +++ b/http/budgeting.go @@ -12,10 +12,11 @@ import ( type BudgetingData struct { AlwaysNeededData - Categories []postgres.GetCategoriesWithBalanceRow - Date time.Time - Next time.Time - Previous time.Time + Categories []postgres.GetCategoriesWithBalanceRow + AvailableBalance postgres.Numeric + Date time.Time + Next time.Time + Previous time.Time } func (h *Handler) budgeting(c *gin.Context) { @@ -64,9 +65,16 @@ func (h *Handler) budgeting(c *gin.Context) { return } + availableBalance, err := h.Service.DB.GetAvailableBalance(c.Request.Context(), budgetUUID) + if err != nil { + c.AbortWithError(http.StatusInternalServerError, err) + return + } + d := BudgetingData{ c.MustGet("data").(AlwaysNeededData), categories, + availableBalance, firstOfMonth, firstOfNextMonth, firstOfPreviousMonth, diff --git a/postgres/budgets.sql.go b/postgres/budgets.sql.go index e4827e1..5dde96c 100644 --- a/postgres/budgets.sql.go +++ b/postgres/budgets.sql.go @@ -13,30 +13,40 @@ const createBudget = `-- name: CreateBudget :one INSERT INTO budgets (name, last_modification) VALUES ($1, NOW()) -RETURNING id, name, last_modification +RETURNING id, name, last_modification, income_category_id ` func (q *Queries) CreateBudget(ctx context.Context, name string) (Budget, error) { row := q.db.QueryRowContext(ctx, createBudget, name) var i Budget - err := row.Scan(&i.ID, &i.Name, &i.LastModification) + err := row.Scan( + &i.ID, + &i.Name, + &i.LastModification, + &i.IncomeCategoryID, + ) return i, err } const getBudget = `-- name: GetBudget :one -SELECT id, name, last_modification FROM budgets +SELECT id, name, last_modification, income_category_id FROM budgets WHERE id = $1 ` func (q *Queries) GetBudget(ctx context.Context, id uuid.UUID) (Budget, error) { row := q.db.QueryRowContext(ctx, getBudget, id) var i Budget - err := row.Scan(&i.ID, &i.Name, &i.LastModification) + err := row.Scan( + &i.ID, + &i.Name, + &i.LastModification, + &i.IncomeCategoryID, + ) return i, err } const getBudgetsForUser = `-- name: GetBudgetsForUser :many -SELECT budgets.id, budgets.name, budgets.last_modification FROM budgets +SELECT budgets.id, budgets.name, budgets.last_modification, budgets.income_category_id FROM budgets LEFT JOIN user_budgets ON budgets.id = user_budgets.budget_id WHERE user_budgets.user_id = $1 ` @@ -50,7 +60,12 @@ func (q *Queries) GetBudgetsForUser(ctx context.Context, userID uuid.UUID) ([]Bu var items []Budget for rows.Next() { var i Budget - if err := rows.Scan(&i.ID, &i.Name, &i.LastModification); err != nil { + if err := rows.Scan( + &i.ID, + &i.Name, + &i.LastModification, + &i.IncomeCategoryID, + ); err != nil { return nil, err } items = append(items, i) diff --git a/postgres/categories.sql.go b/postgres/categories.sql.go index 644d219..7642991 100644 --- a/postgres/categories.sql.go +++ b/postgres/categories.sql.go @@ -48,6 +48,30 @@ func (q *Queries) CreateCategoryGroup(ctx context.Context, arg CreateCategoryGro return i, err } +const getAvailableBalance = `-- name: GetAvailableBalance :one +SELECT + (( + SELECT SUM(transactions.amount) + FROM transactions + LEFT JOIN categories ON categories.id = transactions.category_id + LEFT JOIN budgets ON budgets.income_category_id = categories.id + WHERE budgets.id = $1 + ) - ( + SELECT SUM(assignments.amount) + FROM assignments + INNER JOIN categories ON categories.id = assignments.category_id + INNER JOIN category_groups ON category_groups.id = categories.category_group_id + WHERE category_groups.budget_id = $1 + ))::decimal(12,2) +` + +func (q *Queries) GetAvailableBalance(ctx context.Context, budgetID uuid.UUID) (Numeric, error) { + row := q.db.QueryRowContext(ctx, getAvailableBalance, budgetID) + var column_1 Numeric + err := row.Scan(&column_1) + return column_1, err +} + const getCategories = `-- name: GetCategories :many SELECT categories.id, categories.category_group_id, categories.name, category_groups.name as group FROM categories INNER JOIN category_groups ON categories.category_group_id = category_groups.id @@ -113,7 +137,16 @@ SELECT categories.id, categories.name, category_groups.name as group, WHERE categories.id = t_this.category_id AND t_this.date BETWEEN $1 AND $2 ) - , 0)::decimal(12,2) as activity + , 0)::decimal(12,2) as activity, + COALESCE( + ( + SELECT SUM(a_hist.amount) + FROM assignments a_hist + WHERE categories.id = a_hist.category_id + AND a_hist.date BETWEEN $1 AND $2 + ) + ,0)::decimal(12,2) as assigned + FROM categories INNER JOIN category_groups ON categories.category_group_id = category_groups.id WHERE category_groups.budget_id = $3 @@ -133,6 +166,7 @@ type GetCategoriesWithBalanceRow struct { Group string Balance Numeric Activity Numeric + Assigned Numeric } func (q *Queries) GetCategoriesWithBalance(ctx context.Context, arg GetCategoriesWithBalanceParams) ([]GetCategoriesWithBalanceRow, error) { @@ -150,6 +184,7 @@ func (q *Queries) GetCategoriesWithBalance(ctx context.Context, arg GetCategorie &i.Group, &i.Balance, &i.Activity, + &i.Assigned, ); err != nil { return nil, err } diff --git a/postgres/models.go b/postgres/models.go index 5e9f22d..2405128 100644 --- a/postgres/models.go +++ b/postgres/models.go @@ -27,6 +27,7 @@ type Budget struct { ID uuid.UUID Name string LastModification sql.NullTime + IncomeCategoryID uuid.UUID } type Category struct { diff --git a/postgres/queries/categories.sql b/postgres/queries/categories.sql index 85d0c7c..3a01632 100644 --- a/postgres/queries/categories.sql +++ b/postgres/queries/categories.sql @@ -43,9 +43,34 @@ SELECT categories.id, categories.name, category_groups.name as group, WHERE categories.id = t_this.category_id AND t_this.date BETWEEN @from_date AND @to_date ) - , 0)::decimal(12,2) as activity + , 0)::decimal(12,2) as activity, + COALESCE( + ( + SELECT SUM(a_hist.amount) + FROM assignments a_hist + WHERE categories.id = a_hist.category_id + AND a_hist.date BETWEEN @from_date AND @to_date + ) + ,0)::decimal(12,2) as assigned + FROM categories INNER JOIN category_groups ON categories.category_group_id = category_groups.id WHERE category_groups.budget_id = @budget_id GROUP BY categories.id, categories.name, category_groups.name -ORDER BY category_groups.name, categories.name; \ No newline at end of file +ORDER BY category_groups.name, categories.name; + +-- name: GetAvailableBalance :one +SELECT + (( + SELECT SUM(transactions.amount) + FROM transactions + LEFT JOIN categories ON categories.id = transactions.category_id + LEFT JOIN budgets ON budgets.income_category_id = categories.id + WHERE budgets.id = @budget_id + ) - ( + SELECT SUM(assignments.amount) + FROM assignments + INNER JOIN categories ON categories.id = assignments.category_id + INNER JOIN category_groups ON category_groups.id = categories.category_group_id + WHERE category_groups.budget_id = @budget_id + ))::decimal(12,2); \ No newline at end of file diff --git a/postgres/schema/202112072032_income-category.sql b/postgres/schema/202112072032_income-category.sql new file mode 100644 index 0000000..03fe5ce --- /dev/null +++ b/postgres/schema/202112072032_income-category.sql @@ -0,0 +1,14 @@ +-- +goose Up +ALTER TABLE budgets ADD COLUMN income_category_id uuid NULL REFERENCES categories (id); +UPDATE budgets +SET income_category_id = ( + SELECT categories.id + FROM categories + LEFT JOIN category_groups ON category_groups.id = categories.category_group_id + WHERE categories.name = 'Ready to Assign' + AND category_groups.budget_id = budgets.id +); +ALTER TABLE budgets ALTER COLUMN income_category_id SET NOT NULL; + +-- +goose Down +ALTER TABLE budgets DROP COLUMN income_category_id; \ No newline at end of file diff --git a/web/budgeting.html b/web/budgeting.html index 08b2b05..b1d8911 100644 --- a/web/budgeting.html +++ b/web/budgeting.html @@ -19,12 +19,16 @@ Current Month - Next Month +
+ Available Balance: {{template "amount" .AvailableBalance}} +
+ @@ -36,6 +40,7 @@ + {{template "amount-cell" .Assigned}} {{template "amount-cell" .Balance}} {{template "amount-cell" .Activity}}
Group Category Assigned Balance Activity