From 9eef994eb32650dfe74c0edcb6cfff0e397ae947 Mon Sep 17 00:00:00 2001 From: Jason Gessner Date: Mon, 17 Feb 2025 21:39:04 +0000 Subject: [PATCH 1/2] Add a view for cut conversion rates by id. --- .gitignore | 1 - Gemfile | 1 + Gemfile.lock | 4 + ...50217212451_create_cut_conversion_rates.rb | 5 ++ db/schema.rb | 75 +++++++++++++++++- db/views/cut_conversion_rates_v01.sql | 77 +++++++++++++++++++ 6 files changed, 161 insertions(+), 2 deletions(-) create mode 100644 db/migrate/20250217212451_create_cut_conversion_rates.rb create mode 100644 db/views/cut_conversion_rates_v01.sql diff --git a/.gitignore b/.gitignore index f3127acd..6fe59738 100644 --- a/.gitignore +++ b/.gitignore @@ -23,7 +23,6 @@ cobra_test # Ignore db dumps *.data *.data.gz -*.sql *.sql.gz public/scoop.png diff --git a/Gemfile b/Gemfile index 21347f2e..5b1e2f9c 100644 --- a/Gemfile +++ b/Gemfile @@ -26,6 +26,7 @@ gem 'pundit' gem 'rails', '~> 7' gem 'rqrcode' gem 'sassc-rails' +gem 'scenic' gem 'simple_form' gem 'slim-rails' gem 'turbolinks', '~> 5' diff --git a/Gemfile.lock b/Gemfile.lock index 7e9e2a5b..7e8fe94b 100644 --- a/Gemfile.lock +++ b/Gemfile.lock @@ -370,6 +370,9 @@ GEM sprockets (> 3.0) sprockets-rails tilt + scenic (1.8.0) + activerecord (>= 4.0.0) + railties (>= 4.0.0) securerandom (0.4.1) simple_form (5.3.1) actionpack (>= 5.2) @@ -481,6 +484,7 @@ DEPENDENCIES rubocop-rspec rubocop-rspec_rails sassc-rails + scenic simple_form simplecov simplecov-cobertura diff --git a/db/migrate/20250217212451_create_cut_conversion_rates.rb b/db/migrate/20250217212451_create_cut_conversion_rates.rb new file mode 100644 index 00000000..41c42cf3 --- /dev/null +++ b/db/migrate/20250217212451_create_cut_conversion_rates.rb @@ -0,0 +1,5 @@ +class CreateCutConversionRates < ActiveRecord::Migration[7.2] + def change + create_view :cut_conversion_rates + end +end diff --git a/db/schema.rb b/db/schema.rb index 4c6dfad9..88fec606 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_194837) do +ActiveRecord::Schema[7.2].define(version: 2025_02_17_212451) do # These are extensions that must be enabled in order to support this database enable_extension "plpgsql" @@ -253,4 +253,77 @@ add_foreign_key "standing_rows", "players" add_foreign_key "standing_rows", "stages" add_foreign_key "tournaments", "users" + + create_view "cut_conversion_rates", sql_definition: <<-SQL + WITH corps AS ( + SELECT s_1.tournament_id, + s_1.number AS stage_number, + s_1.id AS stage_id, + 'corp'::text AS side, + COALESCE(id.name, 'Unspecified'::character varying) AS identity, + COALESCE(id.faction, 'Unspecified'::character varying) AS faction + FROM (((stages s_1 + JOIN registrations r ON ((s_1.id = r.stage_id))) + JOIN players p ON ((r.player_id = p.id))) + LEFT JOIN identities id ON ((p.corp_identity_ref_id = id.id))) + ), runners AS ( + SELECT s_1.tournament_id, + s_1.number AS stage_number, + s_1.id AS stage_id, + 'runner'::text AS side, + COALESCE(id.name, 'Unspecified'::character varying) AS identity, + COALESCE(id.faction, 'Unspecified'::character varying) AS faction + 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))) + ), combined AS ( + SELECT corps.tournament_id, + corps.stage_number, + corps.stage_id, + corps.side, + corps.identity, + corps.faction + FROM corps + UNION ALL + SELECT runners.tournament_id, + runners.stage_number, + runners.stage_id, + runners.side, + runners.identity, + runners.faction + FROM runners + ), swiss AS ( + SELECT combined.tournament_id, + combined.stage_id, + combined.stage_number, + combined.side, + combined.identity, + combined.faction, + count(*) AS num_players + FROM combined + WHERE (combined.stage_number = 1) + GROUP BY combined.tournament_id, combined.stage_id, combined.stage_number, combined.side, combined.identity, combined.faction + ), cut AS ( + SELECT combined.tournament_id, + combined.stage_id, + combined.stage_number, + combined.side, + combined.identity, + combined.faction, + count(*) AS num_players + FROM combined + WHERE (combined.stage_number = 2) + GROUP BY combined.tournament_id, combined.stage_id, combined.stage_number, combined.side, combined.identity, combined.faction + ) + SELECT s.tournament_id, + s.side, + 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; + SQL end diff --git a/db/views/cut_conversion_rates_v01.sql b/db/views/cut_conversion_rates_v01.sql new file mode 100644 index 00000000..60cbf4f8 --- /dev/null +++ b/db/views/cut_conversion_rates_v01.sql @@ -0,0 +1,77 @@ +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.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) +GROUP BY s.tournament_id, s.side, s.identity; \ No newline at end of file From b6e9a802f0d639b67b7e26bd4dbaa74cc72d8b0d Mon Sep 17 00:00:00 2001 From: Jason Gessner Date: Mon, 17 Feb 2025 21:44:15 +0000 Subject: [PATCH 2/2] Fix lint. --- db/migrate/20250217212451_create_cut_conversion_rates.rb | 2 ++ 1 file changed, 2 insertions(+) diff --git a/db/migrate/20250217212451_create_cut_conversion_rates.rb b/db/migrate/20250217212451_create_cut_conversion_rates.rb index 41c42cf3..64992e99 100644 --- a/db/migrate/20250217212451_create_cut_conversion_rates.rb +++ b/db/migrate/20250217212451_create_cut_conversion_rates.rb @@ -1,3 +1,5 @@ +# frozen_string_literal: true + class CreateCutConversionRates < ActiveRecord::Migration[7.2] def change create_view :cut_conversion_rates