home / season_25_matches

pirate_cove_towers (view)

22 rows

✎ View and edit SQL

This data as json, CSV (advanced)

Suggested facets: Wins

Tower Games Wins Losses Winrate Pickrate Winrate_LowerBound_95CI
MortarMonkey 592 338 254 57.09% 7.79% 53.11%
BananaFarm 1561 852 709 54.58% 20.53% 52.11%
BombShooter 269 155 114 57.62% 3.54% 51.72%
TackShooter 1623 856 767 52.74% 21.35% 50.31%
WizardMonkey 708 357 351 50.42% 9.31% 46.74%
GlueGunner 480 236 244 49.17% 6.31% 44.69%
IceMonkey 267 134 133 50.19% 3.51% 44.19%
EngineerMonkey 130 65 65 50.00% 1.71% 41.40%
DartlingGunner 95 47 48 49.47% 1.25% 39.42%
MonkeySub 158 73 85 46.20% 2.08% 38.43%
Alchemist 119 56 63 47.06% 1.57% 38.09%
DartMonkey 186 84 102 45.16% 2.45% 38.01%
SniperMonkey 282 120 162 42.55% 3.71% 36.78%
NinjaMonkey 175 71 104 40.57% 2.30% 33.30%
MonkeyAce 87 38 49 43.68% 1.14% 33.26%
MonkeyBuccaneer 90 38 52 42.22% 1.18% 32.02%
MonkeyVillage 255 94 161 36.86% 3.35% 30.94%
HeliPilot 84 34 50 40.48% 1.10% 29.98%
BoomerangMonkey 143 50 93 34.97% 1.88% 27.15%
SuperMonkey 128 45 83 35.16% 1.68% 26.88%
SpikeFactory 106 37 69 34.91% 1.39% 25.83%
Druid 64 21 43 32.81% 0.84% 21.31%

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 1100.645ms