-
Notifications
You must be signed in to change notification settings - Fork 13
Commit
This commit does not belong to any branch on this repository, and may belong to a fork outside of the repository.
Add a view for cut conversion rates by id. (#413)
* Add a view for cut conversion rates by id. * Fix lint.
- Loading branch information
Showing
6 changed files
with
163 additions
and
2 deletions.
There are no files selected for viewing
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
Original file line number | Diff line number | Diff line change |
---|---|---|
|
@@ -23,7 +23,6 @@ cobra_test | |
# Ignore db dumps | ||
*.data | ||
*.data.gz | ||
*.sql | ||
*.sql.gz | ||
|
||
public/scoop.png | ||
|
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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 |
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
This file contains bidirectional Unicode text that may be interpreted or compiled differently than what appears below. To review, open the file in an editor that reveals hidden Unicode characters.
Learn more about bidirectional Unicode characters
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; |