Листа на трансакции кои го надминале балансот на сите сметки вкупно подредени хронолошки
CREATE OR REPLACE FUNCTION get_transactions_exceeding_user_total_balance()
RETURNS TABLE (
user_id INT,
user_name TEXT,
transaction_id INT,
transaction_name TEXT,
transaction_amount NUMERIC,
transaction_date TIMESTAMP,
calculated_total_balance NUMERIC
)
LANGUAGE plpgsql
AS $$
BEGIN
RETURN QUERY
WITH cumulative_totals AS (
SELECT
u.user_id,
u.user_name,
t.transaction_id,
t.transaction_name,
tb.spent_amount AS transaction_amount,
t.date AS transaction_date,
SUM(tb.earned_amount - tb.spent_amount)
OVER (PARTITION BY u.user_id ORDER BY t.date)
AS calculated_total_balance
FROM transaction_account ta
JOIN "user" u ON ta.user_id = u.user_id
JOIN transaction_breakdown tb ON ta.transaction_account_id = tb.transaction_account_id
JOIN transaction t ON tb.transaction_id = t.transaction_id
)
SELECT *
FROM cumulative_totals
WHERE transaction_amount > calculated_total_balance
AND transaction_amount > 0
ORDER BY user_id, transaction_date DESC;
END;
$$;
Релациона алгебра
- U(user_id, user_name)
- TA(transaction_account_id, user_id)
- TB(transaction_id, transaction_account_id, spent_amount, earned_amount)
- T(transaction_id, transaction_name, date)
JOIN на сите табели:
- J1 ← TA ⨝TA.user_id = U.user_id U
- J2 ← J1 ⨝TA.transaction_account_id = TB.transaction_account_id TB
- J3 ← J2 ⨝TB.transaction_id = T.transaction_id T
Пресметка на вкупен кумулативен баланс по корисник:
- CT ← γuser_id, user_name, transaction_id, transaction_name, transaction_amount, transaction_date; Σ(transaction_amount) OVER (PARTITION BY user_id ORDER BY transaction_date) → calculated_total_balance(J3)
каде transaction_amount = spent_amount и кумулативната сума е
Σ(earned_amount - spent_amount) за сите сметки на корисникот
Филтрирање на трансакции кои го надминуваат вкупниот баланс:
- R ← σtransaction_amount > calculated_total_balance ∧ transaction_amount > 0(CT)
Подредување хронолошки (по корисник, од најнова кон најстара трансакција):
- R_final ← τuser_id, transaction_date DESC(R)
Last modified
5 days ago
Last modified on 12/29/25 19:00:42
Note:
See TracWiki
for help on using the wiki.
