88 lines
3.6 KiB
SQL
88 lines
3.6 KiB
SQL
-- name: CreateCategoryGroup :one
|
|
INSERT INTO category_groups
|
|
(name, budget_id)
|
|
VALUES ($1, $2)
|
|
RETURNING *;
|
|
|
|
-- name: GetCategoryGroups :many
|
|
SELECT category_groups.* FROM category_groups
|
|
WHERE category_groups.budget_id = $1;
|
|
|
|
-- name: CreateCategory :one
|
|
INSERT INTO categories
|
|
(name, category_group_id)
|
|
VALUES ($1, $2)
|
|
RETURNING *;
|
|
|
|
-- name: GetCategories :many
|
|
SELECT categories.*, category_groups.name as group FROM categories
|
|
INNER JOIN category_groups ON categories.category_group_id = category_groups.id
|
|
WHERE category_groups.budget_id = $1;
|
|
|
|
-- name: GetCategoriesWithBalance :many
|
|
SELECT categories.id, categories.name, category_groups.name as group,
|
|
(
|
|
COALESCE((
|
|
SELECT SUM(a_hist.amount) FROM assignments a_hist
|
|
WHERE categories.id = a_hist.category_id AND a_hist.date < @to_date
|
|
), 0)+COALESCE((
|
|
SELECT SUM(t_hist.amount) FROM transactions t_hist
|
|
WHERE categories.id = t_hist.category_id AND t_hist.date < @to_date
|
|
), 0)
|
|
)::decimal(12,2) as available,
|
|
( COALESCE((
|
|
SELECT SUM(a_hist.amount) FROM assignments a_hist
|
|
WHERE categories.id = a_hist.category_id AND a_hist.date < @from_date
|
|
), 0)+COALESCE((
|
|
SELECT SUM(t_hist.amount) FROM transactions t_hist
|
|
WHERE categories.id = t_hist.category_id AND t_hist.date < @from_date
|
|
), 0)-CASE WHEN (COALESCE((
|
|
SELECT SUM(a_hist.amount) FROM assignments a_hist
|
|
WHERE categories.id = a_hist.category_id AND a_hist.date < @prev_from_date
|
|
), 0)+COALESCE((
|
|
SELECT SUM(t_hist.amount) FROM transactions t_hist
|
|
WHERE categories.id = t_hist.category_id AND t_hist.date < @prev_from_date
|
|
), 0)) < 0 THEN (COALESCE((
|
|
SELECT SUM(a_hist.amount) FROM assignments a_hist
|
|
WHERE categories.id = a_hist.category_id AND a_hist.date < @prev_from_date
|
|
), 0)+COALESCE((
|
|
SELECT SUM(t_hist.amount) FROM transactions t_hist
|
|
WHERE categories.id = t_hist.category_id AND t_hist.date < @prev_from_date
|
|
), 0)) ELSE 0 END
|
|
|
|
|
|
)::decimal(12,2) as available_last_month,
|
|
COALESCE((
|
|
SELECT SUM(t_this.amount) FROM transactions t_this
|
|
WHERE categories.id = t_this.category_id AND t_this.date >= @from_date AND t_this.date < @to_date
|
|
), 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 >= @from_date AND a_hist.date < @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;
|
|
|
|
-- 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
|
|
INNER JOIN accounts ON accounts.id = transactions.account_id
|
|
WHERE budgets.id = @budget_id
|
|
AND transactions.date < @from_date
|
|
AND accounts.on_budget
|
|
) - (
|
|
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
|
|
AND assignments.date < @from_date
|
|
))::decimal(12,2); |