Skip to content

Commit

Permalink
Add a JSON endpoint for cut conversion rates. (#414)
Browse files Browse the repository at this point in the history
  • Loading branch information
plural authored Feb 21, 2025
1 parent 1390f64 commit 1f90120
Show file tree
Hide file tree
Showing 6 changed files with 142 additions and 4 deletions.
8 changes: 7 additions & 1 deletion app/controllers/tournaments_controller.rb
Original file line number Diff line number Diff line change
Expand Up @@ -5,7 +5,7 @@ class TournamentsController < ApplicationController
show edit update destroy
upload_to_abr save_json cut qr registration timer
close_registration open_registration lock_player_registrations unlock_player_registrations
id_and_faction_data
id_and_faction_data cut_conversion_rates
]

def index
Expand Down Expand Up @@ -223,6 +223,12 @@ def unlock_player_registrations
redirect_back(fallback_location: tournament_rounds_path(@tournament))
end

def cut_conversion_rates
authorize @tournament, :show?

render json: @tournament.cut_conversion_rates_data
end

def id_and_faction_data
authorize @tournament, :show?

Expand Down
45 changes: 45 additions & 0 deletions app/models/tournament.rb
Original file line number Diff line number Diff line change
Expand Up @@ -218,6 +218,51 @@ def self.registration_consent_notice
'decklists, they may be shared with participants or made public.'
end

def cut_conversion_rates_data
sql = ActiveRecord::Base.sanitize_sql([
'SELECT * FROM cut_conversion_rates WHERE tournament_id = ?', id
])
rows = ActiveRecord::Base.connection.exec_query(sql).to_a
results = {
factions: {
corp: {},
runner: {}
},
identities: {
corp: {},
runner: {}
}
}

rows.each do |row|
side = row['side'].to_sym

# Make a place for factions
unless results[:factions][side].key?(row['faction'])
results[:factions][side][row['faction']] =
{ num_swiss_players: 0, num_cut_players: 0,
cut_conversion_percentage: 0.0 }
end

results[:factions][side][row['faction']][:num_swiss_players] += row['num_swiss_players'].to_i
results[:factions][side][row['faction']][:num_cut_players] += row['num_cut_players'].to_i

# Identities are already unique, so just insert them into results.
results[:identities][side][row['identity']] = {
num_swiss_players: row['num_swiss_players'].to_i,
num_cut_players: row['num_cut_players'].to_i,
cut_conversion_percentage: row['cut_conversion_percentage']
}
end
results[:factions].each_key do |side|
results[:factions][side].each do |faction, data|
results[:factions][side][faction][:cut_conversion_percentage] =
(data[:num_cut_players].to_f / data[:num_swiss_players]) * 100
end
end
results
end

private

def default_date
Expand Down
1 change: 1 addition & 0 deletions config/routes.rb
Original file line number Diff line number Diff line change
Expand Up @@ -40,6 +40,7 @@
post :upload_to_abr, on: :member
get :save_json, on: :member
get :id_and_faction_data, on: :member
get :cut_conversion_rates, on: :member
post :cut, on: :member
get :qr, on: :member
get :registration, on: :member
Expand Down
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
# frozen_string_literal: true

class UpdateCutConversionRatesToVersion2 < ActiveRecord::Migration[7.2]
def change
update_view :cut_conversion_rates, version: 2, revert_to_version: 1
end
end
7 changes: 4 additions & 3 deletions db/schema.rb
Original file line number Diff line number Diff line change
Expand Up @@ -10,7 +10,7 @@
#
# It's strongly recommended that you check this file into your version control system.

ActiveRecord::Schema[7.2].define(version: 2025_02_17_212451) do
ActiveRecord::Schema[7.2].define(version: 2025_02_17_220510) do
# These are extensions that must be enabled in order to support this database
enable_extension "plpgsql"

Expand Down Expand Up @@ -318,12 +318,13 @@
)
SELECT s.tournament_id,
s.side,
s.faction,
s.identity,
sum(s.num_players) AS num_swiss_players,
sum(COALESCE(c.num_players, (0)::bigint)) AS num_cut_players,
((sum(COALESCE(c.num_players, (0)::bigint)) / sum(s.num_players)) * (100)::numeric) AS cut_conversion_percentage
FROM (swiss s
LEFT JOIN cut c USING (tournament_id, side, identity))
GROUP BY s.tournament_id, s.side, s.identity;
LEFT JOIN cut c USING (tournament_id, side, identity, faction))
GROUP BY s.tournament_id, s.faction, s.side, s.identity;
SQL
end
78 changes: 78 additions & 0 deletions db/views/cut_conversion_rates_v02.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,78 @@
WITH corps AS (
SELECT s.tournament_id,
s.number AS stage_number,
s.id AS stage_id,
'corp' AS side,
COALESCE(id.name, 'Unspecified') as identity,
COALESCE(id.faction, 'Unspecified') as faction
FROM stages s
JOIN registrations r ON s.id = r.stage_id
JOIN players p ON r.player_id = p.id
LEFT JOIN identities AS id ON p.corp_identity_ref_id = id.id
),
runners AS (
SELECT s.tournament_id,
s.number AS stage_number,
s.id AS stage_id,
'runner' AS side,
COALESCE(id.name, 'Unspecified') as identity,
COALESCE(id.faction, 'Unspecified') as faction
FROM stages s
JOIN registrations r ON s.id = r.stage_id
JOIN players p ON r.player_id = p.id
JOIN identities AS id ON p.runner_identity_ref_id = id.id
),
combined AS (
SELECT *
FROM corps
UNION ALL
SELECT *
FROM runners
),
swiss AS (
SELECT tournament_id,
stage_id,
stage_number,
side,
identity,
faction,
COUNT(*) AS num_players
FROM combined
WHERE stage_number = 1
GROUP BY 1,
2,
3,
4,
5,
6
),
cut AS (
SELECT
tournament_id,
stage_id,
stage_number,
side,
identity,
faction,
COUNT(*) AS num_players
FROM combined
WHERE stage_number = 2
GROUP BY
tournament_id,
stage_id,
stage_number,
side,
identity,
faction
)
SELECT
s.tournament_id,
s.side,
s.faction,
s.identity,
SUM(s.num_players) AS num_swiss_players,
SUM(COALESCE(c.num_players, 0)) AS num_cut_players,
(SUM(COALESCE(c.num_players, 0)) / SUM(s.num_players)) * 100 AS cut_conversion_percentage
FROM swiss s
LEFT JOIN cut c USING (tournament_id, side, identity, faction)
GROUP BY s.tournament_id, s.faction, s.side, s.identity;

0 comments on commit 1f90120

Please sign in to comment.