home / season_28_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
DartMonkey 510 329 181 64.51% 7.51% 60.36%
MortarMonkey 161 105 56 65.22% 2.37% 57.86%
SpikeFactory 583 341 242 58.49% 8.58% 54.49%
BananaFarm 1355 760 595 56.09% 19.95% 53.45%
MonkeyAce 516 273 243 52.91% 7.60% 48.60%
Alchemist 487 250 237 51.33% 7.17% 46.90%
DartlingGunner 569 283 286 49.74% 8.38% 45.63%
EngineerMonkey 240 120 120 50.00% 3.53% 43.67%
MonkeySub 361 167 194 46.26% 5.32% 41.12%
IceMonkey 62 33 29 53.23% 0.91% 40.81%
BoomerangMonkey 256 111 145 43.36% 3.77% 37.29%
MonkeyBuccaneer 227 93 134 40.97% 3.34% 34.57%
SniperMonkey 297 115 182 38.72% 4.37% 33.18%
Druid 99 41 58 41.41% 1.46% 31.71%
NinjaMonkey 155 58 97 37.42% 2.28% 29.80%
WizardMonkey 259 92 167 35.52% 3.81% 29.69%
MonkeyVillage 140 51 89 36.43% 2.06% 28.46%
GlueGunner 150 54 96 36.00% 2.21% 28.32%
TackShooter 109 40 69 36.70% 1.60% 27.65%
SuperMonkey 135 46 89 34.07% 1.99% 26.08%
BombShooter 46 14 32 30.43% 0.68% 17.14%
HeliPilot 75 20 55 26.67% 1.10% 16.66%

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