| | 1 | ===== Листа на трансакции кои го надминале балансот на една сметка подредени хронолошки |
| | 2 | {{{#!sql |
| | 3 | CREATE OR REPLACE FUNCTION get_transactions_exceeding_account_balance( |
| | 4 | p_account_name TEXT |
| | 5 | ) |
| | 6 | RETURNS TABLE ( |
| | 7 | user_id INT, |
| | 8 | user_name TEXT, |
| | 9 | account_name TEXT, |
| | 10 | transaction_id INT, |
| | 11 | transaction_name TEXT, |
| | 12 | transaction_amount NUMERIC, |
| | 13 | transaction_date TIMESTAMP, |
| | 14 | calculated_balance NUMERIC |
| | 15 | ) |
| | 16 | LANGUAGE plpgsql |
| | 17 | AS $$ |
| | 18 | BEGIN |
| | 19 | RETURN QUERY |
| | 20 | WITH cumulative_balances AS ( |
| | 21 | SELECT |
| | 22 | u.user_id, |
| | 23 | u.user_name, |
| | 24 | ta.account_name, |
| | 25 | t.transaction_id, |
| | 26 | t.transaction_name, |
| | 27 | tb.spent_amount AS transaction_amount, |
| | 28 | t.date AS transaction_date, |
| | 29 | SUM(tb.earned_amount - tb.spent_amount) |
| | 30 | OVER (PARTITION BY ta.transaction_account_id ORDER BY t.date) |
| | 31 | AS calculated_balance |
| | 32 | FROM transaction_account ta |
| | 33 | JOIN "user" u ON ta.user_id = u.user_id |
| | 34 | JOIN transaction_breakdown tb ON ta.transaction_account_id = tb.transaction_account_id |
| | 35 | JOIN transaction t ON tb.transaction_id = t.transaction_id |
| | 36 | WHERE ta.account_name = p_account_name |
| | 37 | ) |
| | 38 | SELECT * |
| | 39 | FROM cumulative_balances |
| | 40 | WHERE transaction_amount > calculated_balance |
| | 41 | AND transaction_amount > 0 |
| | 42 | ORDER BY transaction_date DESC; |
| | 43 | END; |
| | 44 | $$; |
| | 45 | |
| | 46 | }}} |