worldcup2022: add winnings column to leaderboard.

There is probably a more compact way to write this SQL. I don't know
what it is. But it works and should be reasonably efficient.
pull/26/head
Snakes 2022-11-27 18:04:14 -05:00
parent 5d49821e7a
commit 8eb50d8bf9
Signed by: Snakes
GPG Key ID: E745A82778055C7E
2 changed files with 82 additions and 27 deletions

View File

@ -2,34 +2,87 @@ from flask import g, jsonify, render_template
from files.helpers.get import get_accounts_dict
from files.routes.wrappers import auth_required
from files.__main__ import app
from files.__main__ import app, cache
_event_leaderboard_query = """
WITH bet_options AS (
SELECT p.id AS submission_id, so.id AS option_id, so.exclusive, cnt.count
FROM submission_options so
JOIN submissions p ON so.submission_id = p.id
JOIN (
SELECT option_id, COUNT(*) FROM submission_option_votes
GROUP BY option_id
) AS cnt ON so.id = cnt.option_id
WHERE p.author_id = 30 AND p.created_utc > 1668953400
AND so.exclusive IN (2, 3)
),
submission_payouts AS (
SELECT
sq_total.submission_id,
sq_winners.sum AS bettors,
floor((sq_total.sum * 200) / sq_winners.sum) AS winner_payout
FROM (
SELECT submission_id, SUM(count)
FROM bet_options GROUP BY submission_id
) AS sq_total
JOIN (
SELECT submission_id, SUM(count)
FROM bet_options WHERE exclusive = 3 GROUP BY submission_id
) AS sq_winners ON sq_total.submission_id = sq_winners.submission_id
),
bet_votes AS (
SELECT
opt.option_id AS option_id,
opt.exclusive,
sov.user_id,
CASE
WHEN opt.exclusive = 2 THEN -200
WHEN opt.exclusive = 3 THEN payout.winner_payout
END payout
FROM submission_option_votes sov
LEFT OUTER JOIN bet_options AS opt
ON opt.option_id = sov.option_id
LEFT OUTER JOIN submission_payouts AS payout
ON opt.submission_id = payout.submission_id
WHERE opt.option_id IS NOT NULL
),
bettors AS (
SELECT
COALESCE(bet_won.user_id, bet_lost.user_id) AS user_id,
(COALESCE(bet_won.count_won, 0)
+ COALESCE(bet_lost.count_lost, 0)) AS bets_total,
COALESCE(bet_won.count_won, 0) AS bets_won
FROM (
SELECT user_id, COUNT(*) AS count_won FROM bet_votes
WHERE exclusive = 3 GROUP BY user_id) AS bet_won
FULL OUTER JOIN (
SELECT user_id, COUNT(*) AS count_lost FROM bet_votes
WHERE exclusive = 2 GROUP BY user_id
) AS bet_lost ON bet_won.user_id = bet_lost.user_id
)
SELECT
bettors.user_id,
bettors.bets_won,
bettors.bets_total,
bet_payout.net AS payout
FROM bettors
LEFT OUTER JOIN (
SELECT user_id, SUM(payout) AS net FROM bet_votes GROUP BY user_id
) AS bet_payout ON bettors.user_id = bet_payout.user_id
ORDER BY payout DESC, bets_won DESC, bets_total ASC;
"""
@cache.memoize(timeout=60)
def _event_leaderboard_get():
result = g.db.execute(_event_leaderboard_query).all()
return result
@app.get('/events/worldcup2022/leaderboard')
@auth_required
def get_leaderboard(v):
result = g.db.execute('''WITH bet_votes AS (
SELECT opt.id AS option_id, opt.exclusive, sov.user_id
FROM submission_option_votes sov
LEFT OUTER JOIN (
SELECT so.id, so.exclusive
FROM submission_options so
JOIN submissions p ON so.submission_id = p.id
WHERE p.author_id = 30 AND p.created_utc > 1668953400 AND so.exclusive IN (2, 3)
) AS opt ON opt.id = sov.option_id
WHERE opt.id IS NOT NULL
)
SELECT
COALESCE(bet_won.user_id, bet_lost.user_id) AS user_id,
(COALESCE(bet_won.count_won, 0) + COALESCE(bet_lost.count_lost, 0)) AS bets_total,
COALESCE(bet_won.count_won, 0) AS bets_won
FROM (
SELECT user_id, COUNT(*) AS count_won FROM bet_votes
WHERE exclusive = 3 GROUP BY user_id) AS bet_won
FULL OUTER JOIN (
SELECT user_id, COUNT(*) AS count_lost FROM bet_votes
WHERE exclusive = 2 GROUP BY user_id) AS bet_lost
ON bet_won.user_id = bet_lost.user_id
ORDER BY bets_won DESC, bets_total ASC;''').all()
result = _event_leaderboard_get()
if g.is_api_or_xhr: return jsonify(result)
users = get_accounts_dict([r[0] for r in result], v=v, include_shadowbanned=False)
return render_template("event/worldcup22_leaderboard.html", v=v, result=result, users=users)
users = get_accounts_dict([r[0] for r in result],
v=v, include_shadowbanned=False)
return render_template("event/worldcup22_leaderboard.html",
v=v, result=result, users=users)

View File

@ -10,6 +10,7 @@
<th onclick="sort_table(1)">Name</th>
<th onclick="sort_table(2)">Wins</th>
<th onclick="sort_table(3)">Bets</th>
<th onclick="sort_table(4)">Winnings</th>
</tr>
</thead>
<tbody>
@ -18,8 +19,9 @@
{% set user = users.get(r[0]) %}
<td>{{loop.index}}</td>
<td data-sort-key="{{user.username.lower() if user else ''}}">{%- include 'user_in_table.html' -%}</td>
<td>{{r[2]}}</td>
<td>{{r[1]}}</td>
<td>{{r[2]}}</td>
<td>{{r[3]}}</td>
</tr>
{% endfor %}
</tbody>