home / season_31_matches

basalt_columns_towers (view)

21 rows

✎ View and edit SQL

This data as json, CSV (advanced)

Tower Games Wins Losses Winrate Pickrate Winrate_LowerBound_95CI
Alchemist 362 203 159 56.08% 5.99% 50.96%
DartlingGunner 627 342 285 54.55% 10.38% 50.65%
BananaFarm 1191 634 557 53.23% 19.71% 50.40%
BoomerangMonkey 235 130 105 55.32% 3.89% 48.96%
MonkeySub 320 174 146 54.38% 5.30% 48.92%
MortarMonkey 83 48 35 57.83% 1.37% 47.21%
MonkeyAce 359 186 173 51.81% 5.94% 46.64%
DartMonkey 213 110 103 51.64% 3.53% 44.93%
SpikeFactory 451 218 233 48.34% 7.46% 43.72%
WizardMonkey 423 200 223 47.28% 7.00% 42.52%
EngineerMonkey 232 113 119 48.71% 3.84% 42.28%
MonkeyBuccaneer 199 96 103 48.24% 3.29% 41.30%
NinjaMonkey 146 72 74 49.32% 2.42% 41.21%
SuperMonkey 165 78 87 47.27% 2.73% 39.65%
IceMonkey 142 67 75 47.18% 2.35% 38.97%
SniperMonkey 267 110 157 41.20% 4.42% 35.29%
Druid 68 31 37 45.59% 1.13% 33.75%
GlueGunner 100 43 57 43.00% 1.66% 33.30%
HeliPilot 123 49 74 39.84% 2.04% 31.19%
MonkeyVillage 159 59 100 37.11% 2.63% 29.60%
TackShooter 146 52 94 35.62% 2.42% 27.85%

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