From 3d616bff50f5d57e26158801a0aacc22ab65542c Mon Sep 17 00:00:00 2001 From: Muyao CHEN Date: Sat, 19 Oct 2024 17:08:05 +0200 Subject: [PATCH] db: finish sql commands --- README.md | 64 +++-- .../howmuch/adapter/repo/sqlc/expense.sql | 72 +++++ .../howmuch/adapter/repo/sqlc/expense.sql.go | 264 ++++++++++++++++++ internal/howmuch/adapter/repo/sqlc/models.go | 4 +- .../howmuch/adapter/repo/sqlc/transaction.sql | 5 + .../adapter/repo/sqlc/transaction.sql.go | 41 +++ internal/howmuch/model/expense.go | 81 ++++-- ...create_transaction_table.postgres.down.sql | 1 - ...12255_create_expense_table.postgres.up.sql | 4 +- ...1_fk_transaction_expense.postgres.down.sql | 1 + 10 files changed, 493 insertions(+), 44 deletions(-) create mode 100644 internal/howmuch/adapter/repo/sqlc/expense.sql create mode 100644 internal/howmuch/adapter/repo/sqlc/expense.sql.go create mode 100644 internal/howmuch/adapter/repo/sqlc/transaction.sql create mode 100644 internal/howmuch/adapter/repo/sqlc/transaction.sql.go diff --git a/README.md b/README.md index 65f4dfb..cc024c5 100644 --- a/README.md +++ b/README.md @@ -421,27 +421,28 @@ The following basic use cases are to be implemented at the first time. - [X] A user signs up - [X] A user logs in -- [X] A user lists their events (pagination) -- [X] A user sees the detail of an event (description, members, amount) -- [] A user sees the expenses of an event (total amount, personal expenses, pagination) -- [] A user sees the detail of an expense: (time, amount, payers, recipients) -- [] A user adds an expense -- [] A user updates/changes an expense (may handle some extra access control) -- [] A user deletes an expense (may handle some extra access control) -- [] A user restore a deleted expense -- [] A user can pay the debt to other members -- [X] A user creates an event (and participate to it) -- [X] A user updates the event info -- [X] A user invites another user by sending a mail with a token. -- [X] A user joins an event by accepting an invitation -- [] ~A user quits an event (they cannot actually, but we can make as if they quitted)~ -**No we can't quit!** -- [] A user cannot see other user's information -- [] A user cannot see the events that they didn't participated in. +- [ ] A user lists their events (pagination) +- [ ] A user sees the detail of an event (description, members, amount) +- [ ] A user sees the expenses of an event (total amount, personal expenses, pagination) +- [ ] A user sees the detail of an expense: (time, amount, payers, recipients) +- [ ] A user adds an expense +- [ ] A user updates/changes an expense (may handle some extra access control) +- [ ] A user can pay the debt to other members (just a special case of expense) +- [ ] A user creates an event (and participate to it) +- [ ] A user updates the event info +- [ ] A user invites another user by sending a mail with a token. +- [ ] A user joins an event by accepting an invitation +- [ ] A user cannot see other user's information +- [ ] A user cannot see the events that they didn't participated in. For the second stage: -- [] A user can archive an event +- [ ] A user can archive an event +- [ ] A user deletes an expense (may handle some extra access control) +- [ ] A user restore a deleted expense +- [ ] Audit log for expense updates/deletes +- [ ] ~A user quits an event (they cannot actually, but we can make as if they +quitted)~ **No we can't quit!** With those functionalities, there will be an usable product. And then we can work on other aspects. For example: @@ -491,3 +492,30 @@ GROUP BY o.id, o.first_name, o.last_name; ``` + +### 2024/10/19 + +I don't plan to handle deletions at this first stage, but I note down what I +have thought of. + +1. Just delete. But keep a replica at the front end of the object that we are +deleting. And propose an option to restore (so a new record is added to the DB) +2. Just delete, but wait. The request is sent to a queue with a timeout of +several seconds, if the user regrets, they can cancel the request. This can be +done on the front, but also on the back. I think it is better to do in on the +front-end. +3. Never deletes. But keep a state in the DB `deleted`. They will just be +ignored when counting. +4. Deletes when doing database cleanup. They lines deleted will be processed +when we cleanup the DB. And they will be definitely deleted at that time. + +I can create a audit log table to log all the critical +changes in my `expense` table (update or delete). + +Finished with the basic SQL commands. Learned a lot from SQL about `JOIN`, +aggregation and `CTE`. SQL itself has quite amount of things to learn, this +is on my future learning plan! + +_I found it quite interesting that simply with SQL, we can simulate the most +business logic. It is a must-have competence for software design and +development._ diff --git a/internal/howmuch/adapter/repo/sqlc/expense.sql b/internal/howmuch/adapter/repo/sqlc/expense.sql new file mode 100644 index 0000000..40d42ba --- /dev/null +++ b/internal/howmuch/adapter/repo/sqlc/expense.sql @@ -0,0 +1,72 @@ +-- name: InsertExpense :one +INSERT INTO "expense" ( + created_at, updated_at, amount, currency, event_id, name, place +) VALUES ( $1, $2, $3, $4, $5, $6, $7 ) +RETURNING *; + +-- name: DeleteExpense :exec +DELETE FROM "expense" WHERE id = $1; + +-- name: DeleteTransactionsOfExpenseID :exec +DELETE FROM "transaction" WHERE transaction.expense_id = $1; + +-- name: UpdateExpenseByID :one +UPDATE "expense" +SET updated_at = $2, amount = $3, currency = $4, name = $5, place = $6 +WHERE id = $1 +RETURNING *; + +-- name: ListExpensesByEventID :many +SELECT + ex.id, ex.created_at, ex.updated_at, ex.amount, ex.currency, ex.event_id, + ex.name, ex.place +FROM "expense" ex +JOIN "event" ev ON ev.id = ex.event_id +WHERE ev.id = $1; + +-- name: ListExpensesByEventIDByUserID :many +SELECT + ex.id, ex.created_at, ex.updated_at, ex.amount, ex.currency, ex.event_id, + ex.name, ex.place +FROM "expense" ex +JOIN "event" ev ON ev.id = ex.event_id +WHERE ev.id = $1; + +-- name: GetExpenseByID :one +WITH payer_transaction as ( + SELECT pt.expense_id, + json_agg(json_build_object( + 'payer_id', p.id, + 'payer_first_name', p.first_name, + 'payer_last_name', p.last_name, + 'amount', pt.amount, + 'currency', pt.currency + )) AS payments + FROM "transaction" pt + JOIN "user" p ON p.id = pt.user_id + WHERE pt.is_income = FALSE + GROUP BY pt.expense_id +), -- For each expense, aggregate payment info +recipient_transaction as ( + SELECT rt.expense_id, + json_agg(json_build_object( + 'recipient_id', p.id, + 'recipient_first_name', p.first_name, + 'recipient_last_name', p.last_name, + 'amount', rt.amount, + 'currency', rt.currency + )) AS benefits + FROM "transaction" rt + JOIN "user" p ON p.id = rt.user_id + WHERE rt.is_income = TRUE + GROUP BY rt.expense_id +) -- For each expense, aggregate benefits info +SELECT + ex.id, ex.created_at, ex.updated_at, ex.amount, ex.currency, ex.event_id, + ex.name, ex.place, + COALESCE(pt.payments, '[]') AS payments, + COALESCE(rt.benefits, '[]') AS benefits +FROM "expense" ex +LEFT JOIN "payer_transaction" pt ON pt.expense_id = ex.id +LEFT JOIN "recipient_transaction" rt ON rt.expense_id = ex.id +WHERE ex.id = $1; diff --git a/internal/howmuch/adapter/repo/sqlc/expense.sql.go b/internal/howmuch/adapter/repo/sqlc/expense.sql.go new file mode 100644 index 0000000..65d8dc3 --- /dev/null +++ b/internal/howmuch/adapter/repo/sqlc/expense.sql.go @@ -0,0 +1,264 @@ +// Code generated by sqlc. DO NOT EDIT. +// versions: +// sqlc v1.27.0 +// source: expense.sql + +package sqlc + +import ( + "context" + "database/sql" + "encoding/json" + "time" +) + +const deleteExpense = `-- name: DeleteExpense :exec +DELETE FROM "expense" WHERE id = $1 +` + +func (q *Queries) DeleteExpense(ctx context.Context, id int32) error { + _, err := q.db.ExecContext(ctx, deleteExpense, id) + return err +} + +const deleteTransactionsOfExpenseID = `-- name: DeleteTransactionsOfExpenseID :exec +DELETE FROM "transaction" WHERE transaction.expense_id = $1 +` + +func (q *Queries) DeleteTransactionsOfExpenseID(ctx context.Context, expenseID int32) error { + _, err := q.db.ExecContext(ctx, deleteTransactionsOfExpenseID, expenseID) + return err +} + +const getExpenseByID = `-- name: GetExpenseByID :one +WITH payer_transaction as ( + SELECT pt.expense_id, + json_agg(json_build_object( + 'payer_id', p.id, + 'payer_first_name', p.first_name, + 'payer_last_name', p.last_name, + 'amount', pt.amount, + 'currency', pt.currency + )) AS payments + FROM "transaction" pt + JOIN "user" p ON p.id = pt.user_id + WHERE pt.is_income = FALSE + GROUP BY pt.expense_id +), -- For each expense, aggregate payment info +recipient_transaction as ( + SELECT rt.expense_id, + json_agg(json_build_object( + 'recipient_id', p.id, + 'recipient_first_name', p.first_name, + 'recipient_last_name', p.last_name, + 'amount', rt.amount, + 'currency', rt.currency + )) AS benefits + FROM "transaction" rt + JOIN "user" p ON p.id = rt.user_id + WHERE rt.is_income = TRUE + GROUP BY rt.expense_id +) -- For each expense, aggregate benefits info +SELECT + ex.id, ex.created_at, ex.updated_at, ex.amount, ex.currency, ex.event_id, + ex.name, ex.place, + COALESCE(pt.payments, '[]') AS payments, + COALESCE(rt.benefits, '[]') AS benefits +FROM "expense" ex +LEFT JOIN "payer_transaction" pt ON pt.expense_id = ex.id +LEFT JOIN "recipient_transaction" rt ON rt.expense_id = ex.id +WHERE ex.id = $1 +` + +type GetExpenseByIDRow struct { + ID int32 + CreatedAt time.Time + UpdatedAt time.Time + Amount int32 + Currency string + EventID int32 + Name sql.NullString + Place sql.NullString + Payments json.RawMessage + Benefits json.RawMessage +} + +func (q *Queries) GetExpenseByID(ctx context.Context, id int32) (GetExpenseByIDRow, error) { + row := q.db.QueryRowContext(ctx, getExpenseByID, id) + var i GetExpenseByIDRow + err := row.Scan( + &i.ID, + &i.CreatedAt, + &i.UpdatedAt, + &i.Amount, + &i.Currency, + &i.EventID, + &i.Name, + &i.Place, + &i.Payments, + &i.Benefits, + ) + return i, err +} + +const insertExpense = `-- name: InsertExpense :one +INSERT INTO "expense" ( + created_at, updated_at, amount, currency, event_id, name, place +) VALUES ( $1, $2, $3, $4, $5, $6, $7 ) +RETURNING id, created_at, updated_at, amount, currency, event_id, name, place +` + +type InsertExpenseParams struct { + CreatedAt time.Time + UpdatedAt time.Time + Amount int32 + Currency string + EventID int32 + Name sql.NullString + Place sql.NullString +} + +func (q *Queries) InsertExpense(ctx context.Context, arg InsertExpenseParams) (Expense, error) { + row := q.db.QueryRowContext(ctx, insertExpense, + arg.CreatedAt, + arg.UpdatedAt, + arg.Amount, + arg.Currency, + arg.EventID, + arg.Name, + arg.Place, + ) + var i Expense + err := row.Scan( + &i.ID, + &i.CreatedAt, + &i.UpdatedAt, + &i.Amount, + &i.Currency, + &i.EventID, + &i.Name, + &i.Place, + ) + return i, err +} + +const listExpensesByEventID = `-- name: ListExpensesByEventID :many +SELECT + ex.id, ex.created_at, ex.updated_at, ex.amount, ex.currency, ex.event_id, + ex.name, ex.place +FROM "expense" ex +JOIN "event" ev ON ev.id = ex.event_id +WHERE ev.id = $1 +` + +func (q *Queries) ListExpensesByEventID(ctx context.Context, id int32) ([]Expense, error) { + rows, err := q.db.QueryContext(ctx, listExpensesByEventID, id) + if err != nil { + return nil, err + } + defer rows.Close() + var items []Expense + for rows.Next() { + var i Expense + if err := rows.Scan( + &i.ID, + &i.CreatedAt, + &i.UpdatedAt, + &i.Amount, + &i.Currency, + &i.EventID, + &i.Name, + &i.Place, + ); 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 listExpensesByEventIDByUserID = `-- name: ListExpensesByEventIDByUserID :many +SELECT + ex.id, ex.created_at, ex.updated_at, ex.amount, ex.currency, ex.event_id, + ex.name, ex.place +FROM "expense" ex +JOIN "event" ev ON ev.id = ex.event_id +WHERE ev.id = $1 +` + +func (q *Queries) ListExpensesByEventIDByUserID(ctx context.Context, id int32) ([]Expense, error) { + rows, err := q.db.QueryContext(ctx, listExpensesByEventIDByUserID, id) + if err != nil { + return nil, err + } + defer rows.Close() + var items []Expense + for rows.Next() { + var i Expense + if err := rows.Scan( + &i.ID, + &i.CreatedAt, + &i.UpdatedAt, + &i.Amount, + &i.Currency, + &i.EventID, + &i.Name, + &i.Place, + ); 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 updateExpenseByID = `-- name: UpdateExpenseByID :one +UPDATE "expense" +SET updated_at = $2, amount = $3, currency = $4, name = $5, place = $6 +WHERE id = $1 +RETURNING id, created_at, updated_at, amount, currency, event_id, name, place +` + +type UpdateExpenseByIDParams struct { + ID int32 + UpdatedAt time.Time + Amount int32 + Currency string + Name sql.NullString + Place sql.NullString +} + +func (q *Queries) UpdateExpenseByID(ctx context.Context, arg UpdateExpenseByIDParams) (Expense, error) { + row := q.db.QueryRowContext(ctx, updateExpenseByID, + arg.ID, + arg.UpdatedAt, + arg.Amount, + arg.Currency, + arg.Name, + arg.Place, + ) + var i Expense + err := row.Scan( + &i.ID, + &i.CreatedAt, + &i.UpdatedAt, + &i.Amount, + &i.Currency, + &i.EventID, + &i.Name, + &i.Place, + ) + return i, err +} diff --git a/internal/howmuch/adapter/repo/sqlc/models.go b/internal/howmuch/adapter/repo/sqlc/models.go index 23c941b..1f53388 100644 --- a/internal/howmuch/adapter/repo/sqlc/models.go +++ b/internal/howmuch/adapter/repo/sqlc/models.go @@ -34,8 +34,8 @@ type Expense struct { Amount int32 Currency string EventID int32 - Name sql.NullInt32 - Place sql.NullInt32 + Name sql.NullString + Place sql.NullString } type Participation struct { diff --git a/internal/howmuch/adapter/repo/sqlc/transaction.sql b/internal/howmuch/adapter/repo/sqlc/transaction.sql new file mode 100644 index 0000000..ed9db0c --- /dev/null +++ b/internal/howmuch/adapter/repo/sqlc/transaction.sql @@ -0,0 +1,5 @@ +-- name: InsertTransaction :exec +INSERT INTO "transaction" ( + created_at, updated_at, amount, currency, expense_id, user_id, is_income +) VALUES ( $1, $2, $3, $4, $5, $6, $7 ) +RETURNING *; diff --git a/internal/howmuch/adapter/repo/sqlc/transaction.sql.go b/internal/howmuch/adapter/repo/sqlc/transaction.sql.go new file mode 100644 index 0000000..f467574 --- /dev/null +++ b/internal/howmuch/adapter/repo/sqlc/transaction.sql.go @@ -0,0 +1,41 @@ +// Code generated by sqlc. DO NOT EDIT. +// versions: +// sqlc v1.27.0 +// source: transaction.sql + +package sqlc + +import ( + "context" + "time" +) + +const insertTransaction = `-- name: InsertTransaction :exec +INSERT INTO "transaction" ( + created_at, updated_at, amount, currency, expense_id, user_id, is_income +) VALUES ( $1, $2, $3, $4, $5, $6, $7 ) +RETURNING id, expense_id, user_id, amount, currency, is_income, created_at, updated_at +` + +type InsertTransactionParams struct { + CreatedAt time.Time + UpdatedAt time.Time + Amount int32 + Currency string + ExpenseID int32 + UserID int32 + IsIncome bool +} + +func (q *Queries) InsertTransaction(ctx context.Context, arg InsertTransactionParams) error { + _, err := q.db.ExecContext(ctx, insertTransaction, + arg.CreatedAt, + arg.UpdatedAt, + arg.Amount, + arg.Currency, + arg.ExpenseID, + arg.UserID, + arg.IsIncome, + ) + return err +} diff --git a/internal/howmuch/model/expense.go b/internal/howmuch/model/expense.go index 3988cd5..cae35c9 100644 --- a/internal/howmuch/model/expense.go +++ b/internal/howmuch/model/expense.go @@ -24,14 +24,38 @@ package model import "time" +// {{{ Requrest + type ExpenseRequest struct { - Amount Money `json:"money" binding:"required,number"` - PayerIDs []int `json:"payer_ids" binding:"required"` - RecipientIDs []int `json:"recipient_ids" binding:"required"` - EventID int `json:"event_id" binding:"required"` - Detail ExpenseDetail `json:"detail"` + Amount Money `json:"money" binding:"required"` + Payments []Payment `json:"payments" binding:"required"` + Benefits []Benefit `json:"benefits" binding:"required"` + EventID int `json:"event_id" binding:"required"` + Detail ExpenseDetail `json:"detail"` } +// }}} +// {{{ Response + +type ExpensesListResponse struct { + ID int `json:"id"` + CreatedAt time.Time `json:"created_at"` + UpdatedAt time.Time `json:"updated_at"` + + Amount Money `json:"money"` + EventID int `json:"event_id"` + + Detail ExpenseDetail `json:"detail"` +} + +type ExpenseGetResponse Expense + +// }}} +// {{{ Retrieved + +type ExpensesListRetrieved ExpensesListResponse + +// }}} // {{{ Entity type ExpenseEntity struct { @@ -48,25 +72,40 @@ type ExpenseEntity struct { Place string } +// }}} +// {{{ Domain Models + type ExpenseDetail struct { Name string `json:"name"` Place string `json:"place"` } -// }}} -type Expense struct { - ID int - CreatedAt time.Time - UpdatedAt time.Time - - Amount Money - - // Lazy aggregate using Transaction join - PayerIDs []int - - // Lazy aggregate using Transaction join - RecipientIDs []int - - EventID int - Detail ExpenseDetail +type Payment struct { + PayerID int `json:"payer_id" binding:"required,number"` + PayerFirstName string `json:"payer_first_name"` + PayerLastName string `json:"payer_last_name"` + Amount Money `json:"amount" binding:"required"` } + +type Benefit struct { + RecipientID int `json:"recipient_id" binding:"required,number"` + RecipientFirstName string `json:"recipient_first_name"` + RecipientLastName string `json:"recipient_last_name"` + Amount Money `json:"amount" binding:"required"` +} + +type Expense struct { + ID int `json:"id"` + CreatedAt time.Time `json:"created_at"` + UpdatedAt time.Time `json:"updated_at"` + + Amount Money `json:"money"` + EventID int `json:"event_id"` + + Detail ExpenseDetail `json:"detail"` + + Payments []Payment `json:"payments"` + Benefits []Benefit `json:"benefits"` +} + +// }}} diff --git a/migrations/20241019110734_create_transaction_table.postgres.down.sql b/migrations/20241019110734_create_transaction_table.postgres.down.sql index 1e980ff..8b13789 100644 --- a/migrations/20241019110734_create_transaction_table.postgres.down.sql +++ b/migrations/20241019110734_create_transaction_table.postgres.down.sql @@ -1,2 +1 @@ -CREATE TABLE "transaction"; diff --git a/migrations/20241019112255_create_expense_table.postgres.up.sql b/migrations/20241019112255_create_expense_table.postgres.up.sql index 612a4bf..7b1a877 100644 --- a/migrations/20241019112255_create_expense_table.postgres.up.sql +++ b/migrations/20241019112255_create_expense_table.postgres.up.sql @@ -6,8 +6,8 @@ CREATE TABLE "expense" ( "amount" integer NOT NULL, "currency" character varying NOT NULL, "event_id" integer NOT NULL, - "name" integer NULL, - "place" integer NULL + "name" character varying(255) NULL, + "place" character varying(1000) NULL ); ALTER TABLE "expense" diff --git a/migrations/20241019112421_fk_transaction_expense.postgres.down.sql b/migrations/20241019112421_fk_transaction_expense.postgres.down.sql index e69de29..0090c7d 100644 --- a/migrations/20241019112421_fk_transaction_expense.postgres.down.sql +++ b/migrations/20241019112421_fk_transaction_expense.postgres.down.sql @@ -0,0 +1 @@ +DROP TABLE transaction;