- 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.
191 lines
4.8 KiB
SQL
191 lines
4.8 KiB
SQL
-- name: GetBetStatsByInterval :many
|
|
SELECT DATE_TRUNC(sqlc.narg('interval'), created_at)::timestamp AS date,
|
|
COUNT(*) as total_bets,
|
|
SUM(amount) AS total_stake,
|
|
SUM(
|
|
CASE
|
|
WHEN status = 0 THEN 1
|
|
ELSE 0
|
|
END
|
|
) as active_bets,
|
|
SUM(
|
|
CASE
|
|
WHEN status = 1 THEN 1
|
|
ELSE 0
|
|
END
|
|
) as total_wins,
|
|
SUM(
|
|
CASE
|
|
WHEN status = 2 THEN 1
|
|
ELSE 0
|
|
END
|
|
) as total_losses,
|
|
SUM(
|
|
CASE
|
|
WHEN status = 1 THEN amount * total_odds
|
|
ELSE 0
|
|
END
|
|
) as win_balance,
|
|
COUNT(*) FILTER (
|
|
WHERE status = 5
|
|
) AS number_of_unsettled,
|
|
SUM(
|
|
CASE
|
|
WHEN status = 5 THEN amount
|
|
ELSE 0
|
|
END
|
|
) AS total_unsettled_amount,
|
|
COUNT(*) FILTER (
|
|
WHERE is_shop_bet = TRUE
|
|
) AS total_shop_bets
|
|
FROM bets
|
|
WHERE (
|
|
bets.company_id = sqlc.narg('company_id')
|
|
OR sqlc.narg('company_id') IS NULL
|
|
);
|
|
-- name: GetBetSummary :one
|
|
SELECT SUM(amount) as total_stakes,
|
|
COUNT(*) as total_bets,
|
|
SUM(
|
|
CASE
|
|
WHEN status = 0 THEN 1
|
|
ELSE 0
|
|
END
|
|
) as active_bets,
|
|
SUM(
|
|
CASE
|
|
WHEN status = 1 THEN 1
|
|
ELSE 0
|
|
END
|
|
) as total_wins,
|
|
SUM(
|
|
CASE
|
|
WHEN status = 2 THEN 1
|
|
ELSE 0
|
|
END
|
|
) as total_losses,
|
|
SUM(
|
|
CASE
|
|
WHEN status = 1 THEN amount * total_odds
|
|
ELSE 0
|
|
END
|
|
) as win_balance
|
|
FROM bets
|
|
wHERE (
|
|
user_id = sqlc.narg('user_id')
|
|
OR sqlc.narg('user_id') IS NULL
|
|
)
|
|
AND (
|
|
company_id = sqlc.narg('company_id')
|
|
OR sqlc.narg('company_id') IS NULL
|
|
)
|
|
AND (
|
|
created_at > sqlc.narg('created_before')
|
|
OR sqlc.narg('created_before') IS NULL
|
|
)
|
|
AND (
|
|
created_at < sqlc.narg('created_after')
|
|
OR sqlc.narg('created_after') IS NULL
|
|
);
|
|
-- name: GetBetStats :many
|
|
SELECT DATE(created_at) as date,
|
|
COUNT(*) as total_bets,
|
|
SUM(amount) as total_stakes,
|
|
SUM(
|
|
CASE
|
|
WHEN status = 1 THEN 1
|
|
ELSE 0
|
|
END
|
|
) as total_wins,
|
|
SUM(
|
|
CASE
|
|
WHEN status = 1 THEN amount * total_odds
|
|
ELSE 0
|
|
END
|
|
) as total_payouts,
|
|
AVG(total_odds) as average_odds
|
|
FROM bets
|
|
wHERE (
|
|
user_id = sqlc.narg('user_id')
|
|
OR sqlc.narg('user_id') IS NULL
|
|
)
|
|
AND (
|
|
company_id = sqlc.narg('company_id')
|
|
OR sqlc.narg('company_id') IS NULL
|
|
)
|
|
AND (
|
|
is_shop_bet = sqlc.narg('is_shop_bet')
|
|
OR sqlc.narg('is_shop_bet') IS NULL
|
|
)
|
|
AND (
|
|
cashed_out = sqlc.narg('cashed_out')
|
|
OR sqlc.narg('cashed_out') IS NULL
|
|
)
|
|
AND (
|
|
full_name ILIKE '%' || sqlc.narg('query') || '%'
|
|
OR phone_number ILIKE '%' || sqlc.narg('query') || '%'
|
|
OR sqlc.narg('query') IS NULL
|
|
)
|
|
AND (
|
|
created_at > sqlc.narg('created_before')
|
|
OR sqlc.narg('created_before') IS NULL
|
|
)
|
|
AND (
|
|
created_at < sqlc.narg('created_after')
|
|
OR sqlc.narg('created_after') IS NULL
|
|
)
|
|
GROUP BY DATE(created_at)
|
|
ORDER BY DATE(created_at);
|
|
-- name: GetTotalBetsMadeInRange :one
|
|
SELECT COUNT(*) AS total_bets
|
|
FROM bets
|
|
WHERE created_at BETWEEN sqlc.arg('from') AND sqlc.arg('to');
|
|
-- name: GetTotalCashMadeInRange :one
|
|
SELECT COALESCE(SUM(amount), 0) AS total_cash_made
|
|
FROM bets
|
|
WHERE created_at BETWEEN sqlc.arg('from') AND sqlc.arg('to');
|
|
-- name: GetTotalCashOutInRange :one
|
|
SELECT COALESCE(SUM(amount), 0) AS total_cash_out
|
|
FROM bets
|
|
WHERE created_at BETWEEN sqlc.arg('from') AND sqlc.arg('to')
|
|
AND cashed_out = true;
|
|
-- name: GetTotalCashBacksInRange :one
|
|
SELECT COALESCE(SUM(amount), 0) AS total_cash_backs
|
|
FROM bets
|
|
WHERE created_at BETWEEN sqlc.arg('from') AND sqlc.arg('to')
|
|
AND status = 5;
|
|
-- name: GetMarketPopularity :one
|
|
WITH market_counts AS (
|
|
SELECT DATE(b.created_at) as date,
|
|
bo.market_name,
|
|
COUNT(*) as bet_count,
|
|
ROW_NUMBER() OVER (
|
|
PARTITION BY DATE(b.created_at)
|
|
ORDER BY COUNT(*) DESC
|
|
) as rank
|
|
FROM bets b
|
|
JOIN bet_outcomes bo ON b.id = bo.bet_id
|
|
WHERE bo.market_name IS NOT NULL
|
|
AND (
|
|
user_id = sqlc.narg('user_id')
|
|
OR sqlc.narg('user_id') IS NULL
|
|
)
|
|
AND (
|
|
company_id = sqlc.narg('company_id')
|
|
OR sqlc.narg('company_id') IS NULL
|
|
)
|
|
AND (
|
|
created_at > sqlc.narg('created_before')
|
|
OR sqlc.narg('created_before') IS NULL
|
|
)
|
|
AND (
|
|
created_at < sqlc.narg('created_after')
|
|
OR sqlc.narg('created_after') IS NULL
|
|
)
|
|
GROUP BY DATE(b.created_at),
|
|
bo.market_name
|
|
)
|
|
SELECT date,
|
|
market_name
|
|
FROM market_counts
|
|
WHERE rank = 1; |