Yimaru-BackEnd/db/query/branch_stats.sql

128 lines
3.9 KiB
SQL

-- name: UpdateBranchStats :exec
WITH -- Aggregate bet data per branch
bet_stats AS (
SELECT branch_id,
COUNT(*) AS total_bets,
COALESCE(SUM(amount), 0) AS total_stake,
COALESCE(
SUM(amount) * MAX(profit_percent),
0
) AS deducted_stake,
COALESCE(
SUM(
CASE
WHEN cashed_out THEN amount
ELSE 0
END
),
0
) AS total_cash_out,
COALESCE(
SUM(
CASE
WHEN status = 3 THEN amount
ELSE 0
END
),
0
) AS total_cash_backs,
COUNT(*) FILTER (
WHERE status = 5
) AS number_of_unsettled,
COALESCE(
SUM(
CASE
WHEN status = 5 THEN amount
ELSE 0
END
),
0
) AS total_unsettled_amount
FROM shop_bet_detail
LEFT JOIN branches ON branches.id = shop_bet_detail.branch_id
GROUP BY branch_id
),
cashier_stats AS (
SELECT branch_id,
COUNT(*) AS total_cashiers
FROM branch_cashiers
GROUP BY branch_id
)
INSERT INTO branch_stats (
branch_id,
branch_name,
company_id,
company_name,
company_slug,
interval_start,
total_bets,
total_stake,
deducted_stake,
total_cash_out,
total_cash_backs,
number_of_unsettled,
total_unsettled_amount,
total_cashiers,
updated_at
)
SELECT br.id AS branch_id,
br.name AS branch_name,
c.id AS company_id,
c.name AS company_name,
c.slug AS company_slug,
DATE_TRUNC('day', NOW() AT TIME ZONE 'UTC') AS interval_start,
COALESCE(bs.total_bets, 0) AS total_bets,
COALESCE(bs.total_stake, 0) AS total_stake,
COALESCE(bs.deducted_stake, 0) AS deducted_stake,
COALESCE(bs.total_cash_out, 0) AS total_cash_out,
COALESCE(bs.total_cash_backs, 0) AS total_cash_backs,
COALESCE(bs.number_of_unsettled, 0) AS number_of_unsettled,
COALESCE(bs.total_unsettled_amount, 0) AS total_unsettled_amount,
COALESCE(bc.total_cashiers, 0) AS total_cashiers,
NOW() AS updated_at
FROM branches br
LEFT JOIN companies c ON c.id = br.company_id
LEFT JOIN bet_stats bs ON bs.branch_id = br.id
LEFT JOIN cashier_stats bc ON bc.branch_id = br.id ON CONFLICT (branch_id, interval_start) DO
UPDATE
SET total_bets = EXCLUDED.total_bets,
total_stake = EXCLUDED.total_stake,
deducted_stake = EXCLUDED.deducted_stake,
total_cash_out = EXCLUDED.total_cash_out,
total_cash_backs = EXCLUDED.total_cash_backs,
number_of_unsettled = EXCLUDED.number_of_unsettled,
total_unsettled_amount = EXCLUDED.total_unsettled_amount,
total_cashiers = EXCLUDED.total_cashiers,
updated_at = EXCLUDED.updated_at;
-- name: GetBranchStatsByID :many
SELECt *
FROM branch_stats
WHERE branch_id = $1
ORDER BY interval_start DESC;
-- name: GetBranchStats :many
SELECT DATE_TRUNC(sqlc.narg('interval'), interval_start)::timestamp AS interval_start,
branch_stats.branch_id,
branch_stats.branch_name,
branch_stats.company_id,
branch_stats.company_name,
branch_stats.company_slug,
branch_stats.total_bets,
branch_stats.total_stake,
branch_stats.deducted_stake,
branch_stats.total_cash_out,
branch_stats.total_cash_backs,
branch_stats.number_of_unsettled,
branch_stats.total_unsettled_amount,
branch_stats.total_cashiers,
branch_stats.updated_at
FROM branch_stats
WHERE (
branch_stats.branch_id = sqlc.narg('branch_id')
OR sqlc.narg('branch_id') IS NULL
)
AND (
branch_stats.company_id = sqlc.narg('company_id')
OR sqlc.narg('company_id') IS NULL
)
GROUP BY interval_start
ORDER BY interval_start DESC;