revert back to carl's version, previous simplification of playerstats
query doesn't allow calculation of things like variance as added by Eleatic Stranger
This commit is contained in:
commit
e9fa9e4324
|
@ -663,114 +663,145 @@ class FpdbSQLQueries:
|
||||||
ORDER BY h.handStart"""
|
ORDER BY h.handStart"""
|
||||||
|
|
||||||
if(self.dbname == 'MySQL InnoDB'):
|
if(self.dbname == 'MySQL InnoDB'):
|
||||||
self.query['playerStats'] = """ /* format(stats.bigBlind/100,2) as BigBlind */
|
self.query['playerStats'] = """
|
||||||
select /* stats from hudcache */
|
SELECT stats.gametypeId
|
||||||
concat(upper(gt.limitType), ' '
|
,stats.base
|
||||||
,concat(upper(substring(gt.category,1,1)),substring(gt.category,2) ), ' '
|
,stats.limitType
|
||||||
,s.name, ' $' /* limittype category site $Bigbl in one field? */
|
,stats.name
|
||||||
,cast(trim(leading ' ' from
|
,format(stats.bigBlind/100,2) as BigBlind
|
||||||
case when gt.bigBlind < 100 then format(gt.bigBlind/100.0,2)
|
,stats.n
|
||||||
else format(gt.bigBlind/100.0,0)
|
,stats.vpip
|
||||||
end ) as char)
|
,stats.pfr
|
||||||
) AS Game
|
,stats.saw_f
|
||||||
,sum(HDs) as n
|
,stats.sawsd
|
||||||
,format(round(100.0*sum(street0VPI)/sum(HDs)),1) AS vpip
|
,stats.wtsdwsf
|
||||||
,format(round(100.0*sum(street0Aggr)/sum(HDs)),1) AS pfr
|
,stats.wmsd
|
||||||
,format(round(100.0*sum(street1Seen)/sum(HDs)),1) AS saw_f
|
,stats.FlAFq
|
||||||
,format(round(100.0*sum(sawShowdown)/sum(HDs)),1) AS sawsd
|
,stats.TuAFq
|
||||||
,case when sum(street1Seen) = 0 then 'oo'
|
,stats.RvAFq
|
||||||
else format(round(100.0*sum(sawShowdown)/sum(street1Seen)),1)
|
,stats.PFAFq
|
||||||
end AS wtsdwsf
|
,hprof2.sum_profit/100 as Net
|
||||||
,case when sum(sawShowdown) = 0 then 'oo'
|
,(hprof2.sum_profit/stats.bigBlind)/(stats.n/100) as BBlPer100
|
||||||
else format(round(100.0*sum(wonAtSD)/sum(sawShowdown)),1)
|
,hprof2.profitperhand as Profitperhand
|
||||||
end AS wmsd
|
,hprof2.variance as Variance
|
||||||
,case when sum(street1Seen) = 0 then 'oo'
|
FROM
|
||||||
else format(round(100.0*sum(street1Aggr)/sum(street1Seen)),1)
|
(select # stats from hudcache
|
||||||
end AS FlAFq
|
gt.base
|
||||||
,case when sum(street2Seen) = 0 then 'oo'
|
,upper(gt.limitType) limitType
|
||||||
else format(round(100.0*sum(street2Aggr)/sum(street2Seen)),1)
|
,s.name
|
||||||
end AS TuAFq
|
,gt.bigBlind
|
||||||
,case when sum(street3Seen) = 0 then 'oo'
|
,hc.gametypeId
|
||||||
else format(round(100.0*sum(street3Aggr)/sum(street3Seen)),1)
|
,sum(HDs) as n
|
||||||
end AS RvAFq
|
,round(100*sum(street0VPI)/sum(HDs)) as vpip
|
||||||
,case when sum(street1Seen)+sum(street2Seen)+sum(street3Seen) = 0 then 'oo'
|
,round(100*sum(street0Aggr)/sum(HDs)) as pfr
|
||||||
else format(round(100.0*(sum(street1Aggr)+sum(street2Aggr)+sum(street3Aggr))
|
,round(100*sum(street1Seen)/sum(HDs)) AS saw_f
|
||||||
/(sum(street1Seen)+sum(street2Seen)+sum(street3Seen))),1)
|
,round(100*sum(sawShowdown)/sum(HDs)) AS sawsd
|
||||||
end AS PoFAFq
|
,round(100*sum(sawShowdown)/sum(street1Seen)) AS wtsdwsf
|
||||||
,format(sum(totalProfit)/100.0,2) AS Net
|
,round(100*sum(wonAtSD)/sum(sawShowdown)) AS wmsd
|
||||||
,case when sum(HDs) = 0 then 'oo'
|
,round(100*sum(street1Aggr)/sum(street1Seen)) AS FlAFq
|
||||||
else format((sum(totalProfit)/(gt.bigBlind+0.0)) / (sum(HDs)/100.0),2)
|
,round(100*sum(street2Aggr)/sum(street2Seen)) AS TuAFq
|
||||||
end AS BBper100
|
,round(100*sum(street3Aggr)/sum(street3Seen)) AS RvAFq
|
||||||
from Gametypes gt
|
,round(100*(sum(street1Aggr)+sum(street2Aggr)+sum(street3Aggr))
|
||||||
inner join Sites s on (s.Id = gt.siteId)
|
/(sum(street1Seen)+sum(street2Seen)+sum(street3Seen))) AS PFAFq
|
||||||
inner join HudCache hc on (hc.gameTypeId = gt.Id)
|
from Gametypes gt
|
||||||
inner join Players p on (p.id = hc.playerId)
|
inner join Sites s on s.Id = gt.siteId
|
||||||
where hc.playerId in <player_test>
|
inner join HudCache hc on hc.gameTypeId = gt.Id
|
||||||
/* use <gametype_test> here ? */
|
where hc.playerId in <player_test>
|
||||||
-- and stats.n > 100 /* optional stat-based queries */
|
# use <gametype_test> here ?
|
||||||
and gt.type = 'ring'
|
group by hc.gametypeId
|
||||||
-- and stats.gametypeId = 5
|
) stats
|
||||||
-- and p.name = 'xyz' /* could add player_name query here */
|
inner join
|
||||||
group by gt.category
|
( select # profit from handsplayers/handsactions
|
||||||
,gt.limitType
|
hprof.gameTypeId, sum(hprof.profit) sum_profit,
|
||||||
,s.name
|
avg(hprof.profit/100.0) profitperhand,
|
||||||
,gt.bigBlind
|
variance(hprof.profit/100.0) variance
|
||||||
,hc.gametypeId
|
from
|
||||||
order by gt.category, gt.limittype, gt.bigBlind"""
|
(select hp.handId, h.gameTypeId, hp.winnings, SUM(ha.amount)
|
||||||
|
costs, hp.winnings - SUM(ha.amount) profit
|
||||||
|
from HandsPlayers hp
|
||||||
|
inner join Hands h ON h.id = hp.handId
|
||||||
|
inner join HandsActions ha ON ha.handPlayerId = hp.id
|
||||||
|
where hp.playerId in <player_test>
|
||||||
|
# use <gametype_test> here ?
|
||||||
|
and hp.tourneysPlayersId IS NULL
|
||||||
|
group by hp.handId, h.gameTypeId, hp.position, hp.winnings
|
||||||
|
) hprof
|
||||||
|
group by hprof.gameTypeId
|
||||||
|
) hprof2
|
||||||
|
on hprof2.gameTypeId = stats.gameTypeId
|
||||||
|
order by stats.base, stats.limittype, stats.bigBlind"""
|
||||||
elif(self.dbname == 'PostgreSQL'):
|
elif(self.dbname == 'PostgreSQL'):
|
||||||
self.query['playerStats'] = """
|
self.query['playerStats'] = """
|
||||||
select /* stats from hudcache */
|
SELECT stats.gametypeId
|
||||||
upper(gt.limitType) || ' '
|
,stats.base
|
||||||
|| initcap(gt.category) || ' '
|
,stats.limitType
|
||||||
|| s.name || ' $' /* limittype category site $Bigbl in one field? */
|
,stats.name
|
||||||
|| trim(leading ' ' from
|
,(stats.bigBlind/100) as BigBlind
|
||||||
case when gt.bigBlind < 100 then to_char(gt.bigBlind/100.0,'0D00')
|
,stats.n
|
||||||
else to_char(gt.bigBlind/100.0,'99990')
|
,stats.vpip
|
||||||
end ) AS Game
|
,stats.pfr
|
||||||
,sum(HDs) as n
|
,stats.saw_f
|
||||||
,to_char(round(100.0*sum(street0VPI)/sum(HDs)),'90D0') AS vpip
|
,stats.sawsd
|
||||||
,to_char(round(100.0*sum(street0Aggr)/sum(HDs)),'90D0') AS pfr
|
,stats.wtsdwsf
|
||||||
,to_char(round(100.0*sum(street1Seen)/sum(HDs)),'90D0') AS saw_f
|
,stats.wmsd
|
||||||
,to_char(round(100.0*sum(sawShowdown)/sum(HDs)),'90D0') AS sawsd
|
,stats.FlAFq
|
||||||
,case when sum(street1Seen) = 0 then 'oo'
|
,stats.TuAFq
|
||||||
else to_char(round(100.0*sum(sawShowdown)/sum(street1Seen)),'90D0')
|
,stats.RvAFq
|
||||||
end AS wtsdwsf
|
,stats.PFAFq
|
||||||
,case when sum(sawShowdown) = 0 then 'oo'
|
,hprof2.sum_profit/100 as Net
|
||||||
else to_char(round(100.0*sum(wonAtSD)/sum(sawShowdown)),'90D0')
|
,(hprof2.sum_profit/stats.bigBlind)/(stats.n/100) as BBlPer100
|
||||||
end AS wmsd
|
,hprof2.profitperhand as Profitperhand
|
||||||
,case when sum(street1Seen) = 0 then 'oo'
|
,hprof2.variance as Variance
|
||||||
else to_char(round(100.0*sum(street1Aggr)/sum(street1Seen)),'90D0')
|
FROM
|
||||||
end AS FlAFq
|
(select gt.base
|
||||||
,case when sum(street2Seen) = 0 then 'oo'
|
,upper(gt.limitType) as limitType
|
||||||
else to_char(round(100.0*sum(street2Aggr)/sum(street2Seen)),'90D0')
|
,s.name
|
||||||
end AS TuAFq
|
,gt.bigBlind
|
||||||
,case when sum(street3Seen) = 0 then 'oo'
|
,hc.gametypeId
|
||||||
else to_char(round(100.0*sum(street3Aggr)/sum(street3Seen)),'90D0')
|
,sum(HDs) as n
|
||||||
end AS RvAFq
|
,round(100*sum(street0VPI)/sum(HDs)) as vpip
|
||||||
,case when sum(street1Seen)+sum(street2Seen)+sum(street3Seen) = 0 then 'oo'
|
,round(100*sum(street0Aggr)/sum(HDs)) as pfr
|
||||||
else to_char(round(100.0*(sum(street1Aggr)+sum(street2Aggr)+sum(street3Aggr))
|
,round(100*sum(street1Seen)/sum(HDs)) AS saw_f
|
||||||
/(sum(street1Seen)+sum(street2Seen)+sum(street3Seen))),'90D0')
|
,round(100*sum(sawShowdown)/sum(HDs)) AS sawsd
|
||||||
end AS PoFAFq
|
,round(100*sum(sawShowdown)/sum(street1Seen)) AS wtsdwsf
|
||||||
,to_char(sum(totalProfit)/100.0,'9G999G990D00') AS Net
|
,round(100*sum(wonAtSD)/sum(sawShowdown)) AS wmsd
|
||||||
,case when sum(HDs) = 0 then 'oo'
|
,round(100*sum(street1Aggr)/sum(street1Seen)) AS FlAFq
|
||||||
else to_char((sum(totalProfit)/(gt.bigBlind+0.0)) / (sum(HDs)/100.0), '990D00')
|
,round(100*sum(street2Aggr)/sum(street2Seen)) AS TuAFq
|
||||||
end AS BBper100
|
,round(100*sum(street3Aggr)/sum(street3Seen)) AS RvAFq
|
||||||
from Gametypes gt
|
,round(100*(sum(street1Aggr)+sum(street2Aggr)+sum(street3Aggr))
|
||||||
inner join Sites s on (s.Id = gt.siteId)
|
/(sum(street1Seen)+sum(street2Seen)+sum(street3Seen))) AS PFAFq
|
||||||
inner join HudCache hc on (hc.gameTypeId = gt.Id)
|
from Gametypes gt
|
||||||
inner join Players p on (p.id = hc.playerId)
|
inner join Sites s on s.Id = gt.siteId
|
||||||
where hc.playerId in <player_test>
|
inner join HudCache hc on hc.gameTypeId = gt.Id
|
||||||
/* use <gametype_test> here ? */
|
where hc.playerId in <player_test>
|
||||||
-- and stats.n > 100 /* optional stat-based queries */
|
group by gt.base
|
||||||
and gt.type = 'ring'
|
,upper(gt.limitType)
|
||||||
-- and stats.gametypeId = 5
|
,s.name
|
||||||
-- and p.name = 'xyz' /* could add player_name query here */
|
,gt.bigBlind
|
||||||
group by gt.category
|
,hc.gametypeId
|
||||||
,gt.limitType
|
) stats
|
||||||
,s.name
|
inner join
|
||||||
,gt.bigBlind
|
( select
|
||||||
,hc.gametypeId
|
hprof.gameTypeId, sum(hprof.profit) sum_profit,
|
||||||
order by gt.category, gt.limittype, gt.bigBlind"""
|
avg(hprof.profit/100.0) profitperhand,
|
||||||
|
variance(hprof.profit/100.0) variance
|
||||||
|
from
|
||||||
|
(select hp.handId,
|
||||||
|
h.gameTypeId,
|
||||||
|
hp.winnings,
|
||||||
|
SUM(ha.amount) as costs,
|
||||||
|
hp.winnings - SUM(ha.amount) as profit
|
||||||
|
from HandsPlayers hp
|
||||||
|
inner join Hands h ON h.id = hp.handId
|
||||||
|
inner join HandsActions ha ON ha.handPlayerId = hp.id
|
||||||
|
where hp.playerId in <player_test>
|
||||||
|
and hp.tourneysPlayersId IS NULL
|
||||||
|
group by hp.handId, h.gameTypeId, hp.position, hp.winnings
|
||||||
|
) hprof
|
||||||
|
group by hprof.gameTypeId
|
||||||
|
) hprof2
|
||||||
|
on hprof2.gameTypeId = stats.gameTypeId
|
||||||
|
order by stats.base, stats.limittype, stats.bigBlind"""
|
||||||
elif(self.dbname == 'SQLite'):
|
elif(self.dbname == 'SQLite'):
|
||||||
self.query['playerStats'] = """ """
|
self.query['playerStats'] = """ """
|
||||||
|
|
||||||
|
|
|
@ -52,7 +52,7 @@ class GuiPlayerStats (threading.Thread):
|
||||||
tmp = tmp.replace("<player_test>", "(" + str(pid) + ")")
|
tmp = tmp.replace("<player_test>", "(" + str(pid) + ")")
|
||||||
self.cursor.execute(tmp)
|
self.cursor.execute(tmp)
|
||||||
result = self.db.cursor.fetchall()
|
result = self.db.cursor.fetchall()
|
||||||
cols = 14
|
cols = 20
|
||||||
rows = len(result)+1 # +1 for title row
|
rows = len(result)+1 # +1 for title row
|
||||||
self.stats_table = gtk.Table(rows, cols, False)
|
self.stats_table = gtk.Table(rows, cols, False)
|
||||||
self.stats_table.set_col_spacings(4)
|
self.stats_table.set_col_spacings(4)
|
||||||
|
@ -60,7 +60,7 @@ class GuiPlayerStats (threading.Thread):
|
||||||
vbox.add(self.stats_table)
|
vbox.add(self.stats_table)
|
||||||
|
|
||||||
# Create header row
|
# Create header row
|
||||||
titles = ("Game", "Hands", "VPIP", "PFR", "Saw_F", "SawSD", "WtSDwsF", "W$SD", "FlAFq", "TuAFq", "RvAFq", "PFAFq", "Net($)", "BBl/100")
|
titles = ("GID", "base", "Style", "Site", "$BB", "Hands", "VPIP", "PFR", "saw_f", "sawsd", "wtsdwsf", "wmsd", "FlAFq", "TuAFq", "RvAFq", "PFAFq", "Net($)", "BB/100", "$/hand", "Variance")
|
||||||
|
|
||||||
col = 0
|
col = 0
|
||||||
row = 0
|
row = 0
|
||||||
|
|
Loading…
Reference in New Issue
Block a user