home / season_32_matches

pirate_cove_towers (view)

12 rows

✎ View and edit SQL

This data as json, CSV (advanced)

Suggested facets: Wins, Winrate

Tower Games Wins Losses Winrate Pickrate Winrate_LowerBound_95CI
WizardMonkey 581 319 262 54.91% 22.52% 50.86%
BananaFarm 706 363 343 51.42% 27.36% 47.73%
IceMonkey 44 27 17 61.36% 1.71% 46.98%
TackShooter 664 336 328 50.60% 25.74% 46.80%
EngineerMonkey 36 18 18 50.00% 1.40% 33.67%
SniperMonkey 43 20 23 46.51% 1.67% 31.60%
MonkeySub 46 20 26 43.48% 1.78% 29.15%
BoomerangMonkey 53 22 31 41.51% 2.05% 28.24%
NinjaMonkey 48 20 28 41.67% 1.86% 27.72%
MortarMonkey 114 40 74 35.09% 4.42% 26.33%
GlueGunner 45 18 27 40.00% 1.74% 25.69%
Alchemist 24 10 14 41.67% 0.93% 21.94%

Advanced export

JSON shape: default, array, newline-delimited

CSV options:

CREATE VIEW pirate_cove_towers AS 
WITH pirate_cove AS
    (SELECT *
    FROM matches
    WHERE map = 'pirate_cove')
SELECT Tower,
       Games,
       Wins,
       Losses,
       printf('%.2f%%', WR * 100)                                          AS Winrate,
       printf('%.2f%%', PR * 100)                                          AS Pickrate,
       printf('%.2f%%', (WR - 1.96 * SQRT((WR * (1 - WR)) / Games)) * 100) AS Winrate_LowerBound_95CI
FROM (SELECT Tower,
             Games,
             Wins,
             Losses,
             CAST(Wins AS REAL) / Games AS WR,
             CAST(Games AS REAL) / (
                 (SELECT COUNT(*)
                  FROM pirate_cove) * 6)    AS PR
      FROM (SELECT Tower,
                   SUM(Win) + SUM(NOT Win) AS Games,
                   SUM(Win)                AS Wins,
                   SUM(NOT Win)            AS Losses
            FROM (SELECT lt1           AS Tower,
                         playerLeftWin AS Win
                  FROM pirate_cove
                  UNION ALL
                  SELECT lt2           AS Tower,
                         playerLeftWin AS Win
                  FROM pirate_cove
                  UNION ALL
                  SELECT lt3           AS Tower,
                         playerLeftWin AS Win
                  FROM pirate_cove
                  UNION ALL
                  SELECT rt1               AS Tower,
                         NOT playerLeftWin AS Win
                  FROM pirate_cove
                  UNION ALL
                  SELECT rt2               AS Tower,
                         NOT playerLeftWin AS Win
                  FROM pirate_cove
                  UNION ALL
                  SELECT rt3               AS Tower,
                         NOT playerLeftWin AS Win
                  FROM pirate_cove)
            GROUP BY Tower))
WHERE Wins >= 10 AND Losses >= 10 AND LENGTH(Winrate_LowerBound_95CI) = 6
ORDER BY Winrate_LowerBound_95CI DESC;
Powered by Datasette · Queries took 312.602ms