Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Add a view for cut conversion rates by id. #413

Merged
merged 2 commits into from
Feb 17, 2025
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension


Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
1 change: 0 additions & 1 deletion .gitignore
Original file line number Diff line number Diff line change
Expand Up @@ -23,7 +23,6 @@ cobra_test
# Ignore db dumps
*.data
*.data.gz
*.sql
*.sql.gz

public/scoop.png
Expand Down
1 change: 1 addition & 0 deletions Gemfile
Original file line number Diff line number Diff line change
Expand Up @@ -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'
Expand Down
4 changes: 4 additions & 0 deletions Gemfile.lock
Original file line number Diff line number Diff line change
Expand Up @@ -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)
Expand Down Expand Up @@ -481,6 +484,7 @@ DEPENDENCIES
rubocop-rspec
rubocop-rspec_rails
sassc-rails
scenic
simple_form
simplecov
simplecov-cobertura
Expand Down
7 changes: 7 additions & 0 deletions db/migrate/20250217212451_create_cut_conversion_rates.rb
Original file line number Diff line number Diff line change
@@ -0,0 +1,7 @@
# frozen_string_literal: true

class CreateCutConversionRates < ActiveRecord::Migration[7.2]
def change
create_view :cut_conversion_rates
end
end
75 changes: 74 additions & 1 deletion 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_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"

Expand Down Expand Up @@ -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
77 changes: 77 additions & 0 deletions db/views/cut_conversion_rates_v01.sql
Original file line number Diff line number Diff line change
@@ -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;