From c3a022b595ea828608306d5087563df801adeb0c Mon Sep 17 00:00:00 2001 From: Jan Bader Date: Wed, 8 Dec 2021 14:36:34 +0000 Subject: [PATCH] Add views with results grouped by month --- postgres/assignments.sql.go | 35 +++++++++++++++++++ postgres/models.go | 16 +++++++++ postgres/queries/assignments.sql | 5 +++ postgres/queries/transactions.sql | 7 +++- .../schema/202112081529_views-for-months.sql | 17 +++++++++ postgres/transactions.sql.go | 35 +++++++++++++++++++ 6 files changed, 114 insertions(+), 1 deletion(-) create mode 100644 postgres/schema/202112081529_views-for-months.sql diff --git a/postgres/assignments.sql.go b/postgres/assignments.sql.go index 8302a22..9ef2fc6 100644 --- a/postgres/assignments.sql.go +++ b/postgres/assignments.sql.go @@ -52,3 +52,38 @@ func (q *Queries) DeleteAllAssignments(ctx context.Context, budgetID uuid.UUID) } return result.RowsAffected() } + +const getAssignmentsByMonthAndCategory = `-- name: GetAssignmentsByMonthAndCategory :many +SELECT year, month, category_id, budget_id, amount +FROM assignments_by_month +WHERE assignments_by_month.budget_id = $1 +` + +func (q *Queries) GetAssignmentsByMonthAndCategory(ctx context.Context, budgetID uuid.UUID) ([]AssignmentsByMonth, error) { + rows, err := q.db.QueryContext(ctx, getAssignmentsByMonthAndCategory, budgetID) + if err != nil { + return nil, err + } + defer rows.Close() + var items []AssignmentsByMonth + for rows.Next() { + var i AssignmentsByMonth + if err := rows.Scan( + &i.Year, + &i.Month, + &i.CategoryID, + &i.BudgetID, + &i.Amount, + ); err != nil { + return nil, err + } + items = append(items, i) + } + if err := rows.Close(); err != nil { + return nil, err + } + if err := rows.Err(); err != nil { + return nil, err + } + return items, nil +} diff --git a/postgres/models.go b/postgres/models.go index 411c9ff..22139ec 100644 --- a/postgres/models.go +++ b/postgres/models.go @@ -24,6 +24,14 @@ type Assignment struct { Amount Numeric } +type AssignmentsByMonth struct { + Year float64 + Month float64 + CategoryID uuid.UUID + BudgetID uuid.UUID + Amount int64 +} + type Budget struct { ID uuid.UUID Name string @@ -59,6 +67,14 @@ type Transaction struct { PayeeID uuid.NullUUID } +type TransactionsByMonth struct { + Year float64 + Month float64 + CategoryID uuid.NullUUID + BudgetID uuid.UUID + Amount int64 +} + type User struct { ID uuid.UUID Email string diff --git a/postgres/queries/assignments.sql b/postgres/queries/assignments.sql index a0c521e..1cffd54 100644 --- a/postgres/queries/assignments.sql +++ b/postgres/queries/assignments.sql @@ -11,3 +11,8 @@ DELETE FROM assignments USING categories INNER JOIN category_groups ON categories.category_group_id = category_groups.id WHERE categories.id = assignments.category_id AND category_groups.budget_id = @budget_id; + +-- name: GetAssignmentsByMonthAndCategory :many +SELECT * +FROM assignments_by_month +WHERE assignments_by_month.budget_id = @budget_id; \ No newline at end of file diff --git a/postgres/queries/transactions.sql b/postgres/queries/transactions.sql index 3dd6f42..b8c7f92 100644 --- a/postgres/queries/transactions.sql +++ b/postgres/queries/transactions.sql @@ -32,4 +32,9 @@ LIMIT 200; DELETE FROM transactions USING accounts WHERE accounts.budget_id = @budget_id -AND accounts.id = transactions.account_id; \ No newline at end of file +AND accounts.id = transactions.account_id; + +-- name: GetTransactionsByMonthAndCategory :many +SELECT * +FROM transactions_by_month +WHERE transactions_by_month.budget_id = @budget_id; \ No newline at end of file diff --git a/postgres/schema/202112081529_views-for-months.sql b/postgres/schema/202112081529_views-for-months.sql new file mode 100644 index 0000000..d6c5eaf --- /dev/null +++ b/postgres/schema/202112081529_views-for-months.sql @@ -0,0 +1,17 @@ +-- +goose Up +CREATE VIEW transactions_by_month AS + SELECT extract(year from transactions.date) as year, extract(month from transactions.date) as month, transactions.category_id, accounts.budget_id, SUM(amount) as amount + FROM transactions + INNER JOIN accounts ON accounts.id = transactions.account_id + GROUP BY extract(year from transactions.date), extract(month from transactions.date), transactions.category_id, accounts.budget_id; + +CREATE VIEW assignments_by_month AS + SELECT extract(year from assignments.date) as year, extract(month from assignments.date) as month, assignments.category_id, category_groups.budget_id, SUM(amount) as amount + FROM assignments + INNER JOIN categories ON categories.id = assignments.category_id + INNER JOIN category_groups ON categories.category_group_id = category_groups.id + GROUP BY extract(year from assignments.date), extract(month from assignments.date), assignments.category_id, category_groups.budget_id; + +-- +goose Down +DROP VIEW transactions_by_month; +DROP VIEW assignments_by_month; \ No newline at end of file diff --git a/postgres/transactions.sql.go b/postgres/transactions.sql.go index 6de4317..4b427c4 100644 --- a/postgres/transactions.sql.go +++ b/postgres/transactions.sql.go @@ -63,6 +63,41 @@ func (q *Queries) DeleteAllTransactions(ctx context.Context, budgetID uuid.UUID) return result.RowsAffected() } +const getTransactionsByMonthAndCategory = `-- name: GetTransactionsByMonthAndCategory :many +SELECT year, month, category_id, budget_id, amount +FROM transactions_by_month +WHERE transactions_by_month.budget_id = $1 +` + +func (q *Queries) GetTransactionsByMonthAndCategory(ctx context.Context, budgetID uuid.UUID) ([]TransactionsByMonth, error) { + rows, err := q.db.QueryContext(ctx, getTransactionsByMonthAndCategory, budgetID) + if err != nil { + return nil, err + } + defer rows.Close() + var items []TransactionsByMonth + for rows.Next() { + var i TransactionsByMonth + if err := rows.Scan( + &i.Year, + &i.Month, + &i.CategoryID, + &i.BudgetID, + &i.Amount, + ); err != nil { + return nil, err + } + items = append(items, i) + } + if err := rows.Close(); err != nil { + return nil, err + } + if err := rows.Err(); err != nil { + return nil, err + } + return items, nil +} + const getTransactionsForAccount = `-- name: GetTransactionsForAccount :many SELECT transactions.id, transactions.date, transactions.memo, transactions.amount, accounts.name as account, COALESCE(payees.name, '') as payee, COALESCE(category_groups.name, '') as category_group, COALESCE(categories.name, '') as category