- Introduced BetStatStore, BranchStatStore, and WalletStatStore interfaces for handling statistics. - Implemented repository methods for fetching and updating bet, branch, and wallet statistics. - Created reporting services for generating interval reports for bets, branches, companies, and wallets. - Enhanced CSV writing functionality to support dynamic struct to CSV conversion. - Added cron jobs for periodic updates of branch and wallet statistics. - Updated wallet handler to include transaction statistics in the response.
130 lines
4.2 KiB
SQL
130 lines
4.2 KiB
SQL
-- name: UpdateWalletStats :exec
|
|
WITH all_transfers AS (
|
|
SELECT sender_wallet_id AS wallet_id,
|
|
amount,
|
|
type
|
|
FROM wallet_transfer
|
|
WHERE sender_wallet_id IS NOT NULL
|
|
UNION ALL
|
|
SELECT receiver_wallet_id AS wallet_id,
|
|
amount,
|
|
type
|
|
FROM wallet_transfer
|
|
WHERE receiver_wallet_id IS NOT NULL
|
|
),
|
|
transfer_stats AS (
|
|
SELECT wallet_id,
|
|
COUNT(*) AS number_of_transactions,
|
|
COALESCE(SUM(amount), 0) AS total_transactions,
|
|
COUNT(*) FILTER (
|
|
WHERE type = 'deposit'
|
|
) AS number_of_deposits,
|
|
COALESCE(
|
|
SUM(
|
|
CASE
|
|
WHEN type = 'deposit' THEN amount
|
|
ELSE 0
|
|
END
|
|
),
|
|
0
|
|
) AS total_deposits_amount,
|
|
COUNT(*) FILTER (
|
|
WHERE type = 'withdraw'
|
|
) AS number_of_withdraws,
|
|
COALESCE(
|
|
SUM(
|
|
CASE
|
|
WHEN type = 'withdraw' THEN amount
|
|
ELSE 0
|
|
END
|
|
),
|
|
0
|
|
) AS total_withdraws_amount,
|
|
COUNT(*) FILTER (
|
|
WHERE type = 'wallet'
|
|
) AS number_of_transfers,
|
|
COALESCE(
|
|
SUM(
|
|
CASE
|
|
WHEN type = 'wallet' THEN amount
|
|
ELSE 0
|
|
END
|
|
),
|
|
0
|
|
) AS total_transfers_amount
|
|
FROM all_transfers
|
|
GROUP BY wallet_id
|
|
)
|
|
INSERT INTO wallet_stats(
|
|
wallet_id,
|
|
wallet_user_id,
|
|
wallet_user_first_name,
|
|
wallet_user_last_name,
|
|
wallet_type,
|
|
interval_start,
|
|
number_of_transactions,
|
|
total_transactions,
|
|
number_of_deposits,
|
|
total_deposits_amount,
|
|
number_of_withdraws,
|
|
total_withdraws_amount,
|
|
number_of_transfers,
|
|
total_transfers_amount,
|
|
updated_at
|
|
)
|
|
SELECT w.id AS wallet_id,
|
|
w.user_id AS wallet_user_id,
|
|
u.first_name AS wallet_user_first_name,
|
|
u.last_name AS wallet_user_last_name,
|
|
w.type AS wallet_type,
|
|
DATE_TRUNC('day', NOW() AT TIME ZONE 'UTC') AS interval_start,
|
|
COALESCE(ts.number_of_transactions, 0) AS number_of_transactions,
|
|
COALESCE(ts.total_transactions, 0) AS total_transactions,
|
|
COALESCE(ts.number_of_deposits, 0) AS number_of_deposits,
|
|
COALESCE(ts.total_deposits_amount, 0) AS total_deposits_amount,
|
|
COALESCE(ts.number_of_withdraws, 0) AS number_of_withdraws,
|
|
COALESCE(ts.total_withdraws_amount, 0) AS total_withdraws_amount,
|
|
COALESCE(ts.number_of_transfers, 0) AS number_of_transfers,
|
|
COALESCE(ts.total_transfers_amount, 0) AS total_transfers_amount,
|
|
NOW() AS updated_at
|
|
FROM wallets w
|
|
LEFT JOIN users u ON u.id = w.user_id
|
|
LEFT JOIN transfer_stats ts ON ts.wallet_id = w.id ON CONFLICT (wallet_id, interval_start) DO
|
|
UPDATE
|
|
SET number_of_transactions = EXCLUDED.number_of_transactions,
|
|
total_transactions = EXCLUDED.total_transactions,
|
|
number_of_deposits = EXCLUDED.number_of_deposits,
|
|
total_deposits_amount = EXCLUDED.total_deposits_amount,
|
|
number_of_withdraws = EXCLUDED.number_of_withdraws,
|
|
total_withdraws_amount = EXCLUDED.total_withdraws_amount,
|
|
number_of_transfers = EXCLUDED.number_of_transfers,
|
|
total_transfers_amount = EXCLUDED.total_transfers_amount,
|
|
updated_at = EXCLUDED.updated_at;
|
|
-- name: GetWalletStatsByID :many
|
|
SELECT *
|
|
FROM wallet_stats
|
|
WHERE wallet_id = $1
|
|
ORDER BY interval_start DESC;
|
|
-- name: GetWalletStats :many
|
|
SELECT DATE_TRUNC(sqlc.narg('interval'), interval_start)::timestamp AS interval_start,
|
|
wallet_stats.wallet_id,
|
|
wallet_stats.wallet_user_id,
|
|
wallet_stats.wallet_user_first_name,
|
|
wallet_stats.wallet_user_last_name,
|
|
wallet_stats.wallet_type,
|
|
wallet_stats.number_of_transactions,
|
|
wallet_stats.total_transactions,
|
|
wallet_stats.number_of_deposits,
|
|
wallet_stats.total_deposits_amount,
|
|
wallet_stats.number_of_withdraws,
|
|
wallet_stats.total_withdraws_amount,
|
|
wallet_stats.number_of_transfers,
|
|
wallet_stats.total_transfers_amount,
|
|
wallet_stats.updated_at
|
|
FROM wallet_stats
|
|
WHERE (
|
|
wallet_stats.wallet_user_id = sqlc.narg('user_id')
|
|
OR sqlc.narg('user_id') IS NULL
|
|
)
|
|
GROUP BY interval_start
|
|
ORDER BY interval_start DESC; |