get tourney stats working for sqlite and pg (pg display still dodgy, think gui is mangling some fields somehow, e.g. sitename)

This commit is contained in:
sqlcoder 2010-08-12 22:15:44 +01:00
parent 4a3869395c
commit d6c7ccaeff
2 changed files with 73 additions and 10 deletions

View File

@ -86,9 +86,9 @@ class GuiTourneyPlayerStats (GuiPlayerStats.GuiPlayerStats):
, ["playerName", False, "Name", 0.0, "%s", "str"] # true not allowed for this line (set in code) , ["playerName", False, "Name", 0.0, "%s", "str"] # true not allowed for this line (set in code)
, ["tourneyCount", True, "#", 1.0, "%1.0f", "str"] , ["tourneyCount", True, "#", 1.0, "%1.0f", "str"]
, ["itm", True, "ITM%", 1.0, "%3.2f", "str"] , ["itm", True, "ITM%", 1.0, "%3.2f", "str"]
, ["1st", False, "1st", 1.0, "%1.0f", "str"] , ["_1st", False, "1st", 1.0, "%1.0f", "str"]
, ["2nd", True, "2nd", 1.0, "%1.0f", "str"] , ["_2nd", True, "2nd", 1.0, "%1.0f", "str"]
, ["3rd", True, "3rd", 1.0, "%1.0f", "str"] , ["_3rd", True, "3rd", 1.0, "%1.0f", "str"]
, ["unknownRank", True, "Rank?", 1.0, "%1.0f", "str"] , ["unknownRank", True, "Rank?", 1.0, "%1.0f", "str"]
, ["spent", True, "Spent", 1.0, "%3.2f", "str"] , ["spent", True, "Spent", 1.0, "%3.2f", "str"]
, ["won", True, "Won", 1.0, "%3.2f", "str"] , ["won", True, "Won", 1.0, "%3.2f", "str"]

View File

@ -2399,7 +2399,7 @@ class Sql:
select s.name AS siteName select s.name AS siteName
,t.tourneyTypeId AS tourneyTypeId ,t.tourneyTypeId AS tourneyTypeId
,tt.currency AS currency ,tt.currency AS currency
,(CASE WHEN tt.currency = "USD" THEN tt.buyIn/100.0 ELSE tt.buyIn END) AS buyIn ,(CASE WHEN tt.currency = 'USD' THEN tt.buyIn/100.0 ELSE tt.buyIn END) AS buyIn
,tt.fee/100.0 AS fee ,tt.fee/100.0 AS fee
,tt.category AS category ,tt.category AS category
,tt.limitType AS limitType ,tt.limitType AS limitType
@ -2407,11 +2407,11 @@ class Sql:
,COUNT(1) AS tourneyCount ,COUNT(1) AS tourneyCount
,SUM(CASE WHEN tp.rank > 0 THEN 0 ELSE 1 END) AS unknownRank ,SUM(CASE WHEN tp.rank > 0 THEN 0 ELSE 1 END) AS unknownRank
,SUM(CASE WHEN winnings > 0 THEN 1 ELSE 0 END)/(COUNT(1) - SUM(CASE WHEN tp.rank > 0 THEN 0 ELSE 1 END)) AS itm ,SUM(CASE WHEN winnings > 0 THEN 1 ELSE 0 END)/(COUNT(1) - SUM(CASE WHEN tp.rank > 0 THEN 0 ELSE 1 END)) AS itm
,SUM(CASE WHEN rank = 1 THEN 1 ELSE 0 END) AS 1st ,SUM(CASE WHEN rank = 1 THEN 1 ELSE 0 END) AS _1st
,SUM(CASE WHEN rank = 2 THEN 1 ELSE 0 END) AS 2nd ,SUM(CASE WHEN rank = 2 THEN 1 ELSE 0 END) AS _2nd
,SUM(CASE WHEN rank = 3 THEN 1 ELSE 0 END) AS 3rd ,SUM(CASE WHEN rank = 3 THEN 1 ELSE 0 END) AS _3rd
,SUM(tp.winnings)/100.0 AS won ,SUM(tp.winnings)/100.0 AS won
,SUM(CASE WHEN tt.currency = "USD" THEN (tt.buyIn+tt.fee)/100.0 ELSE tt.buyIn END) AS spent ,SUM(CASE WHEN tt.currency = 'USD' THEN (tt.buyIn+tt.fee)/100.0 ELSE tt.buyIn END) AS spent
,SUM(tp.winnings)/SUM(tt.buyin+tt.fee)*100.0-100 AS roi ,SUM(tp.winnings)/SUM(tt.buyin+tt.fee)*100.0-100 AS roi
,SUM(tp.winnings-(tt.buyin+tt.fee))/100.0/(COUNT(1)-SUM(CASE WHEN tp.rank > 0 THEN 0 ELSE 1 END)) AS profitPerTourney ,SUM(tp.winnings-(tt.buyin+tt.fee))/100.0/(COUNT(1)-SUM(CASE WHEN tp.rank > 0 THEN 0 ELSE 1 END)) AS profitPerTourney
from TourneysPlayers tp from TourneysPlayers tp
@ -2426,9 +2426,72 @@ class Sql:
,playerName ,playerName
,siteName""" ,siteName"""
elif db_server == 'postgresql': elif db_server == 'postgresql':
self.query['tourneyPlayerDetailedStats'] = """TODO""" # sc: itm and profitPerTourney changed to "ELSE 0" to avoid divide by zero error as temp fix
# proper fix should use coalesce() or case ... when ... to work in all circumstances
self.query['tourneyPlayerDetailedStats'] = """
select s.name AS siteName
,t.tourneyTypeId AS tourneyTypeId
,tt.currency AS currency
,(CASE WHEN tt.currency = 'USD' THEN tt.buyIn/100.0 ELSE tt.buyIn END) AS buyIn
,tt.fee/100.0 AS fee
,tt.category AS category
,tt.limitType AS limitType
,p.name AS playerName
,COUNT(1) AS tourneyCount
,SUM(CASE WHEN tp.rank > 0 THEN 0 ELSE 1 END) AS unknownRank
,SUM(CASE WHEN winnings > 0 THEN 1 ELSE 0 END)
/(COUNT(1) - SUM(CASE WHEN tp.rank > 0 THEN 0 ELSE 0 END)) AS itm
,SUM(CASE WHEN rank = 1 THEN 1 ELSE 0 END) AS _1st
,SUM(CASE WHEN rank = 2 THEN 1 ELSE 0 END) AS _2nd
,SUM(CASE WHEN rank = 3 THEN 1 ELSE 0 END) AS _3rd
,SUM(tp.winnings)/100.0 AS won
,SUM(CASE WHEN tt.currency = 'USD' THEN (tt.buyIn+tt.fee)/100.0 ELSE tt.buyIn END) AS spent
,SUM(tp.winnings)/SUM(tt.buyin+tt.fee)*100.0-100 AS roi
,SUM(tp.winnings-(tt.buyin+tt.fee))/100.0
/(COUNT(1)-SUM(CASE WHEN tp.rank > 0 THEN 0 ELSE 0 END)) AS profitPerTourney
from TourneysPlayers tp
inner join Tourneys t on (t.id = tp.tourneyId)
inner join TourneyTypes tt on (tt.Id = t.tourneyTypeId)
inner join Sites s on (s.Id = tt.siteId)
inner join Players p on (p.Id = tp.playerId)
where tp.playerId in <nametest> <sitetest>
and to_char(t.startTime, 'YYYY-MM-DD HH24:MI:SS') <datestest>
group by tourneyTypeId, s.name, playerName, tt.currency, tt.buyin, tt.fee
, tt.category, tt.limitType
order by tourneyTypeId
,playerName
,siteName"""
elif db_server == 'sqlite': elif db_server == 'sqlite':
self.query['tourneyPlayerDetailedStats'] = """TODO""" self.query['tourneyPlayerDetailedStats'] = """
select s.name AS siteName
,t.tourneyTypeId AS tourneyTypeId
,tt.currency AS currency
,(CASE WHEN tt.currency = 'USD' THEN tt.buyIn/100.0 ELSE tt.buyIn END) AS buyIn
,tt.fee/100.0 AS fee
,tt.category AS category
,tt.limitType AS limitType
,p.name AS playerName
,COUNT(1) AS tourneyCount
,SUM(CASE WHEN tp.rank > 0 THEN 0 ELSE 1 END) AS unknownRank
,SUM(CASE WHEN winnings > 0 THEN 1 ELSE 0 END)/(COUNT(1) - SUM(CASE WHEN tp.rank > 0 THEN 0 ELSE 1 END)) AS itm
,SUM(CASE WHEN rank = 1 THEN 1 ELSE 0 END) AS _1st
,SUM(CASE WHEN rank = 2 THEN 1 ELSE 0 END) AS _2nd
,SUM(CASE WHEN rank = 3 THEN 1 ELSE 0 END) AS _3rd
,SUM(tp.winnings)/100.0 AS won
,SUM(CASE WHEN tt.currency = 'USD' THEN (tt.buyIn+tt.fee)/100.0 ELSE tt.buyIn END) AS spent
,SUM(tp.winnings)/SUM(tt.buyin+tt.fee)*100.0-100 AS roi
,SUM(tp.winnings-(tt.buyin+tt.fee))/100.0/(COUNT(1)-SUM(CASE WHEN tp.rank > 0 THEN 0 ELSE 1 END)) AS profitPerTourney
from TourneysPlayers tp
inner join Tourneys t on (t.id = tp.tourneyId)
inner join TourneyTypes tt on (tt.Id = t.tourneyTypeId)
inner join Sites s on (s.Id = tt.siteId)
inner join Players p on (p.Id = tp.playerId)
where tp.playerId in <nametest> <sitetest>
and datetime(t.startTime) <datestest>
group by tourneyTypeId, playerName
order by tourneyTypeId
,playerName
,siteName"""
if db_server == 'mysql': if db_server == 'mysql':
self.query['playerStats'] = """ self.query['playerStats'] = """