home / season_26_matches

basalt_columns_towers (view)

22 rows

✎ View and edit SQL

This data as json, CSV (advanced)

Tower Games Wins Losses Winrate Pickrate Winrate_LowerBound_95CI
MortarMonkey 253 165 88 65.22% 3.72% 59.35%
BananaFarm 1093 616 477 56.36% 16.05% 53.42%
DartMonkey 440 255 185 57.95% 6.46% 53.34%
DartlingGunner 496 270 226 54.44% 7.28% 50.05%
BoomerangMonkey 307 167 140 54.40% 4.51% 48.83%
MonkeyAce 505 258 247 51.09% 7.42% 46.73%
SuperMonkey 204 109 95 53.43% 3.00% 46.59%
IceMonkey 87 48 39 55.17% 1.28% 44.72%
MonkeyVillage 177 92 85 51.98% 2.60% 44.62%
Alchemist 482 229 253 47.51% 7.08% 43.05%
SpikeFactory 541 249 292 46.03% 7.94% 41.83%
MonkeySub 270 128 142 47.41% 3.96% 41.45%
EngineerMonkey 159 76 83 47.80% 2.33% 40.03%
SniperMonkey 384 168 216 43.75% 5.64% 38.79%
MonkeyBuccaneer 407 173 234 42.51% 5.98% 37.70%
WizardMonkey 263 114 149 43.35% 3.86% 37.36%
BombShooter 64 31 33 48.44% 0.94% 36.19%
NinjaMonkey 151 63 88 41.72% 2.22% 33.86%
GlueGunner 235 90 145 38.30% 3.45% 32.08%
HeliPilot 93 34 59 36.56% 1.37% 26.77%
Druid 99 35 64 35.35% 1.45% 25.94%
TackShooter 100 35 65 35.00% 1.47% 25.65%

Advanced export

JSON shape: default, array, newline-delimited

CSV options:

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