home / season_32_matches

up_on_the_roof_towers (view)

16 rows

✎ View and edit SQL

This data as json, CSV (advanced)

Suggested facets: Wins, Losses

Tower Games Wins Losses Winrate Pickrate Winrate_LowerBound_95CI
MonkeyVillage 109 65 44 59.63% 10.04% 50.42%
BoomerangMonkey 44 26 18 59.09% 4.05% 44.56%
GlueGunner 45 26 19 57.78% 4.14% 43.35%
Alchemist 47 27 20 57.45% 4.33% 43.31%
DartMonkey 32 19 13 59.38% 2.95% 42.36%
TackShooter 75 40 35 53.33% 6.91% 42.04%
SuperMonkey 86 44 42 51.16% 7.92% 40.60%
NinjaMonkey 73 38 35 52.05% 6.72% 40.59%
DartlingGunner 51 27 24 52.94% 4.70% 39.24%
BananaFarm 99 47 52 47.47% 9.12% 37.64%
SniperMonkey 87 40 47 45.98% 8.01% 35.50%
WizardMonkey 89 40 49 44.94% 8.20% 34.61%
SpikeFactory 81 34 47 41.98% 7.46% 31.23%
HeliPilot 22 11 11 50.00% 2.03% 29.11%
BombShooter 28 11 17 39.29% 2.58% 21.20%
EngineerMonkey 29 11 18 37.93% 2.67% 20.27%

Advanced export

JSON shape: default, array, newline-delimited

CSV options:

CREATE VIEW up_on_the_roof_towers AS 
WITH up_on_the_roof AS
    (SELECT *
    FROM matches
    WHERE map = 'up_on_the_roof')
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 up_on_the_roof) * 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 up_on_the_roof
                  UNION ALL
                  SELECT lt2           AS Tower,
                         playerLeftWin AS Win
                  FROM up_on_the_roof
                  UNION ALL
                  SELECT lt3           AS Tower,
                         playerLeftWin AS Win
                  FROM up_on_the_roof
                  UNION ALL
                  SELECT rt1               AS Tower,
                         NOT playerLeftWin AS Win
                  FROM up_on_the_roof
                  UNION ALL
                  SELECT rt2               AS Tower,
                         NOT playerLeftWin AS Win
                  FROM up_on_the_roof
                  UNION ALL
                  SELECT rt3               AS Tower,
                         NOT playerLeftWin AS Win
                  FROM up_on_the_roof)
            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 280.281ms