diff --git a/app/controllers/tournaments_controller.rb b/app/controllers/tournaments_controller.rb
index c8ee3116..7acd7c02 100644
--- a/app/controllers/tournaments_controller.rb
+++ b/app/controllers/tournaments_controller.rb
@@ -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
@@ -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?
diff --git a/app/models/tournament.rb b/app/models/tournament.rb
index 1a62acec..a169d550 100644
--- a/app/models/tournament.rb
+++ b/app/models/tournament.rb
@@ -218,6 +218,52 @@ 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']] = {
+ faction: row['faction'],
+ 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'].to_f
+ }
+ 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
diff --git a/app/views/tournaments/_player_counts.html.slim b/app/views/tournaments/_player_counts.html.slim
index 620b4623..4e935887 100644
--- a/app/views/tournaments/_player_counts.html.slim
+++ b/app/views/tournaments/_player_counts.html.slim
@@ -75,6 +75,40 @@
th Players
tbody
+ h3 Elimination Cut Conversion Rates
+ .row
+ .col-md-6
+ table.table id="cut_corp_faction_conversion_rate"
+ thead
+ tr
+ th Corp Factions
+ th Players
+ tbody
+
+ .col-md-6
+ table.table id="cut_runner_faction_conversion_rate"
+ thead
+ tr
+ th Runner Factions
+ th Players
+ tbody
+
+ .row
+ .col-md-6
+ table.table id="cut_corp_ids_conversion_rate"
+ thead
+ tr
+ th Corp
+ th Players
+ tbody
+
+ .col-md-6
+ table.table id="cut_runner_ids_conversion_rate"
+ thead
+ tr
+ th Runner
+ th Players
+ tbody
javascript:
function drawPieChart(element, series, labels, colors=null) {
@@ -160,6 +194,94 @@
});
}
+ function populateFactionCutRows(data, side) {
+ factions = [];
+ for (faction in data) {
+ factions.push({
+ name: faction,
+ num_swiss_players: data[faction].num_swiss_players,
+ num_cut_players: data[faction].num_cut_players,
+ cut_conversion_percentage: data[faction].cut_conversion_percentage,
+ });
+ }
+ factions.sort((a, b) => {
+ if (b.cut_conversion_percentage !== a.cut_conversion_percentage) {
+ return b.cut_conversion_percentage - a.cut_conversion_percentage; // Descending order by cut_conversion_percentage
+ } else {
+ return b.num_cut_players - a.num_cut_players; // Descending order by num_cut_players
+ }
+ });
+
+ console.table(factions);
+
+ let tableId = `cut_${side}_faction_conversion_rate`;
+ const tableBody = document.querySelector(`#${tableId} tbody`);
+ factions.forEach((faction) => {
+ const row = document.createElement("tr");
+
+ const idCell = document.createElement("td");
+ idCell.innerHTML = `
${displayFaction(faction.name)}
`;
+ row.appendChild(idCell);
+
+ const countCell = document.createElement("td");
+ countCell.innerHTML = `${faction.num_cut_players} / ${faction.num_swiss_players} (${faction.cut_conversion_percentage.toFixed(1)}%)`;
+ row.appendChild(countCell);
+
+ tableBody.appendChild(row);
+ });
+ }
+
+ function populateIdentityCutRows(data, side) {
+ ids = [];
+ for (id in data) {
+ ids.push({
+ name: id,
+ faction: data[id].faction,
+ num_swiss_players: data[id].num_swiss_players,
+ num_cut_players: data[id].num_cut_players,
+ cut_conversion_percentage: data[id].cut_conversion_percentage,
+ });
+ }
+ ids.sort((a, b) => {
+ if (b.cut_conversion_percentage !== a.cut_conversion_percentage) {
+ return b.cut_conversion_percentage - a.cut_conversion_percentage; // Descending order by cut_conversion_percentage
+ } else {
+ return b.num_cut_players - a.num_cut_players; // Descending order by num_cut_players
+ }
+ });
+
+ console.table(ids);
+
+ let tableId = `cut_${side}_ids_conversion_rate`;
+ const tableBody = document.querySelector(`#${tableId} tbody`);
+ ids.forEach((id) => {
+ const row = document.createElement("tr");
+
+ const idCell = document.createElement("td");
+ idCell.innerHTML = ` ${id.name}
`;
+ row.appendChild(idCell);
+
+ const countCell = document.createElement("td");
+ countCell.innerHTML = `${id.num_cut_players} / ${id.num_swiss_players} (${id.cut_conversion_percentage.toFixed(1)}%)`;
+ row.appendChild(countCell);
+
+ tableBody.appendChild(row);
+ });
+ }
+
+ if (#{@tournament.stages.size} > 1) {
+ fetch('/tournaments/#{@tournament.id}/cut_conversion_rates')
+ .then(response => response.json())
+ .then(data => {
+ populateFactionCutRows(data.factions.corp, 'corp');
+ populateFactionCutRows(data.factions.runner, 'runner');
+
+ populateIdentityCutRows(data.identities.corp, 'corp');
+ populateIdentityCutRows(data.identities.runner, 'runner');
+ })
+ .catch(error => console.error('Error fetching cut conversion rate data:', error));
+ }
+
fetch('/tournaments/#{@tournament.id}/id_and_faction_data')
.then(response => response.json())
.then(data => {
@@ -199,4 +321,4 @@
}
})
- .catch(error => console.error('Error:', error));
+ .catch(error => console.error('Error fetching ID and faction data:', error));
diff --git a/config/routes.rb b/config/routes.rb
index 1605243f..61f597d4 100644
--- a/config/routes.rb
+++ b/config/routes.rb
@@ -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
diff --git a/db/migrate/20250217220510_update_cut_conversion_rates_to_version_2.rb b/db/migrate/20250217220510_update_cut_conversion_rates_to_version_2.rb
new file mode 100644
index 00000000..0950b65e
--- /dev/null
+++ b/db/migrate/20250217220510_update_cut_conversion_rates_to_version_2.rb
@@ -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
diff --git a/db/migrate/20250218061330_update_cut_conversion_rates_to_version_3.rb b/db/migrate/20250218061330_update_cut_conversion_rates_to_version_3.rb
new file mode 100644
index 00000000..eed1f119
--- /dev/null
+++ b/db/migrate/20250218061330_update_cut_conversion_rates_to_version_3.rb
@@ -0,0 +1,7 @@
+# frozen_string_literal: true
+
+class UpdateCutConversionRatesToVersion3 < ActiveRecord::Migration[7.2]
+ def change
+ update_view :cut_conversion_rates, version: 3, revert_to_version: 2
+ end
+end
diff --git a/db/schema.rb b/db/schema.rb
index 88fec606..e81001eb 100644
--- a/db/schema.rb
+++ b/db/schema.rb
@@ -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_18_061330) do
# These are extensions that must be enabled in order to support this database
enable_extension "plpgsql"
@@ -276,7 +276,7 @@
FROM (((stages s_1
JOIN registrations r ON ((s_1.id = r.stage_id)))
JOIN players p ON ((r.player_id = p.id)))
- JOIN identities id ON ((p.runner_identity_ref_id = id.id)))
+ LEFT JOIN identities id ON ((p.runner_identity_ref_id = id.id)))
), combined AS (
SELECT corps.tournament_id,
corps.stage_number,
@@ -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
diff --git a/db/views/cut_conversion_rates_v02.sql b/db/views/cut_conversion_rates_v02.sql
new file mode 100644
index 00000000..5f7d597c
--- /dev/null
+++ b/db/views/cut_conversion_rates_v02.sql
@@ -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;
\ No newline at end of file
diff --git a/db/views/cut_conversion_rates_v03.sql b/db/views/cut_conversion_rates_v03.sql
new file mode 100644
index 00000000..b7b72261
--- /dev/null
+++ b/db/views/cut_conversion_rates_v03.sql
@@ -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
+ LEFT 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;
\ No newline at end of file