73 lines
2.2 KiB
SQL
73 lines
2.2 KiB
SQL
-- 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;
|