add steal stat to positional stats and fix for postgres
This commit is contained in:
parent
1b82ad7f65
commit
fddb29b3b8
|
@ -718,8 +718,8 @@ class FpdbSQLQueries:
|
||||||
avg(hprof.profit/100.0) profitperhand,
|
avg(hprof.profit/100.0) profitperhand,
|
||||||
variance(hprof.profit/100.0) variance
|
variance(hprof.profit/100.0) variance
|
||||||
from
|
from
|
||||||
(select hp.handId, h.gameTypeId, hp.winnings, SUM(ha.amount)
|
(select hp.handId, h.gameTypeId, hp.winnings, SUM(ha.amount) as costs
|
||||||
costs, hp.winnings - SUM(ha.amount) profit
|
, hp.winnings - SUM(ha.amount) as profit
|
||||||
from HandsPlayers hp
|
from HandsPlayers hp
|
||||||
inner join Hands h ON h.id = hp.handId
|
inner join Hands h ON h.id = hp.handId
|
||||||
left join HandsActions ha ON ha.handPlayerId = hp.id
|
left join HandsActions ha ON ha.handPlayerId = hp.id
|
||||||
|
@ -860,6 +860,7 @@ class FpdbSQLQueries:
|
||||||
,stats.n
|
,stats.n
|
||||||
,stats.vpip
|
,stats.vpip
|
||||||
,stats.pfr
|
,stats.pfr
|
||||||
|
,stats.steals
|
||||||
,stats.saw_f
|
,stats.saw_f
|
||||||
,stats.sawsd
|
,stats.sawsd
|
||||||
,stats.wtsdwsf
|
,stats.wtsdwsf
|
||||||
|
@ -898,6 +899,9 @@ class FpdbSQLQueries:
|
||||||
,sum(HDs) AS n
|
,sum(HDs) AS n
|
||||||
,format(100.0*sum(street0VPI)/sum(HDs),1) AS vpip
|
,format(100.0*sum(street0VPI)/sum(HDs),1) AS vpip
|
||||||
,format(100.0*sum(street0Aggr)/sum(HDs),1) AS pfr
|
,format(100.0*sum(street0Aggr)/sum(HDs),1) AS pfr
|
||||||
|
,case when sum(stealattemptchance) = 0 then '0'
|
||||||
|
else format(100.0*sum(stealattempted)/sum(stealattemptchance),1)
|
||||||
|
end AS steals
|
||||||
,format(100.0*sum(street1Seen)/sum(HDs),1) AS saw_f
|
,format(100.0*sum(street1Seen)/sum(HDs),1) AS saw_f
|
||||||
,format(100.0*sum(sawShowdown)/sum(HDs),1) AS sawsd
|
,format(100.0*sum(sawShowdown)/sum(HDs),1) AS sawsd
|
||||||
,case when sum(street1Seen) = 0 then 'oo'
|
,case when sum(street1Seen) = 0 then 'oo'
|
||||||
|
@ -949,8 +953,8 @@ class FpdbSQLQueries:
|
||||||
avg(hprof.profit/100.0) as profitperhand,
|
avg(hprof.profit/100.0) as profitperhand,
|
||||||
variance(hprof.profit/100.0) as variance
|
variance(hprof.profit/100.0) as variance
|
||||||
from
|
from
|
||||||
(select hp.handId, h.gameTypeId, hp.position, hp.winnings, SUM(ha.amount)
|
(select hp.handId, h.gameTypeId, hp.position, hp.winnings, SUM(ha.amount) as costs
|
||||||
costs, hp.winnings - SUM(ha.amount) profit
|
, hp.winnings - SUM(ha.amount) as profit
|
||||||
from HandsPlayers hp
|
from HandsPlayers hp
|
||||||
inner join Hands h ON h.id = hp.handId
|
inner join Hands h ON h.id = hp.handId
|
||||||
left join HandsActions ha ON ha.handPlayerId = hp.id
|
left join HandsActions ha ON ha.handPlayerId = hp.id
|
||||||
|
@ -968,52 +972,138 @@ class FpdbSQLQueries:
|
||||||
elif(self.dbname == 'PostgreSQL'):
|
elif(self.dbname == 'PostgreSQL'):
|
||||||
self.query['playerStatsByPosition'] = """
|
self.query['playerStatsByPosition'] = """
|
||||||
select /* stats from hudcache */
|
select /* stats from hudcache */
|
||||||
hc.position AS pl_position
|
upper(stats.limitType) || ' '
|
||||||
,sum(HDs) as n
|
|| upper(substr(stats.category,1,1)) || substr(stats.category,2) || ' '
|
||||||
,to_char(round(100.0*sum(street0VPI)/sum(HDs)),'90D0') AS vpip
|
|| stats.name || ' $'
|
||||||
,to_char(round(100.0*sum(street0Aggr)/sum(HDs)),'90D0') AS pfr
|
|| trim(leading ' ' from
|
||||||
,to_char(round(100.0*sum(street1Seen)/sum(HDs)),'90D0') AS saw_f
|
case when stats.bigBlind < 100
|
||||||
,to_char(round(100.0*sum(sawShowdown)/sum(HDs)),'90D0') AS sawsd
|
then to_char(stats.bigBlind/100.0,'90D00')
|
||||||
,case when sum(street1Seen) = 0 then 'oo'
|
else to_char(stats.bigBlind/100.0,'999990')
|
||||||
else to_char(round(100.0*sum(sawShowdown)/sum(street1Seen)),'90D0')
|
end ) AS Game
|
||||||
end AS wtsdwsf
|
,case when stats.PlPosition = -2 then 'BB'
|
||||||
,case when sum(sawShowdown) = 0 then 'oo'
|
when stats.PlPosition = -1 then 'SB'
|
||||||
else to_char(round(100.0*sum(wonAtSD)/sum(sawShowdown)),'90D0')
|
when stats.PlPosition = 0 then 'Btn'
|
||||||
end AS wmsd
|
when stats.PlPosition = 1 then 'CO'
|
||||||
,case when sum(street1Seen) = 0 then 'oo'
|
when stats.PlPosition = 2 then 'MP'
|
||||||
else to_char(round(100.0*sum(street1Aggr)/sum(street1Seen)),'90D0')
|
when stats.PlPosition = 5 then 'EP'
|
||||||
end AS FlAFq
|
else '??'
|
||||||
,case when sum(street2Seen) = 0 then 'oo'
|
end AS PlPosition
|
||||||
else to_char(round(100.0*sum(street2Aggr)/sum(street2Seen)),'90D0')
|
,stats.n
|
||||||
end AS TuAFq
|
,stats.vpip
|
||||||
,case when sum(street3Seen) = 0 then 'oo'
|
,stats.pfr
|
||||||
else to_char(round(100.0*sum(street3Aggr)/sum(street3Seen)),'90D0')
|
,stats.steals
|
||||||
end AS RvAFq
|
,stats.saw_f
|
||||||
,case when sum(street1Seen)+sum(street2Seen)+sum(street3Seen) = 0 then 'oo'
|
,stats.sawsd
|
||||||
else to_char(round(100.0*(sum(street1Aggr)+sum(street2Aggr)+sum(street3Aggr))
|
,stats.wtsdwsf
|
||||||
/(sum(street1Seen)+sum(street2Seen)+sum(street3Seen))),'90D0')
|
,stats.wmsd
|
||||||
end AS PoFAFq
|
,stats.FlAFq
|
||||||
,to_char(sum(totalProfit)/100.0,'9G999G990D00') AS Net
|
,stats.TuAFq
|
||||||
,case when sum(HDs) = 0 then 'oo'
|
,stats.RvAFq
|
||||||
else to_char((sum(totalProfit)/(gt.bigBlind+0.0)) / (sum(HDs)/100.0), '990D00')
|
,stats.PoFAFq
|
||||||
end AS BBper100
|
/* if you have handsactions data the next 3 fields should give same answer as
|
||||||
from Gametypes gt
|
following 3 commented out fields */
|
||||||
inner join Sites s on (s.Id = gt.siteId)
|
,stats.Net
|
||||||
inner join HudCache hc on (hc.gameTypeId = gt.Id)
|
,stats.BBper100
|
||||||
inner join Players p on (p.id = hc.playerId)
|
,stats.Profitperhand
|
||||||
where hc.playerId in <player_test>
|
/*,format(hprof2.sum_profit/100.0,2) AS Net
|
||||||
and gt.type = 'ring'
|
,format((hprof2.sum_profit/(stats.bigBlind+0.0)) / (stats.n/100.0),2)
|
||||||
and gt.id = <gametype_test> /* must specify gametypeid */
|
AS BBlPer100
|
||||||
/* and stats.n > 100 optional stat-based queries */
|
,hprof2.profitperhand AS Profitperhand
|
||||||
group by pl_position, gt.bigblind
|
*/
|
||||||
order by case when hc.position = 'B' then -2
|
,to_char(hprof2.variance, '0D00') AS Variance
|
||||||
|
FROM
|
||||||
|
(select /* stats from hudcache */
|
||||||
|
gt.base
|
||||||
|
,gt.category
|
||||||
|
,upper(gt.limitType) as limitType
|
||||||
|
,s.name
|
||||||
|
,gt.bigBlind
|
||||||
|
,hc.gametypeId
|
||||||
|
,case when hc.position = 'B' then -2
|
||||||
when hc.position = 'S' then -1
|
when hc.position = 'S' then -1
|
||||||
when hc.position = 'D' then 0
|
when hc.position = 'D' then 0
|
||||||
when hc.position = 'C' then 1
|
when hc.position = 'C' then 1
|
||||||
when hc.position = 'M' then 2
|
when hc.position = 'M' then 2
|
||||||
when hc.position = 'E' then 5
|
when hc.position = 'E' then 5
|
||||||
else 9
|
else 9
|
||||||
end
|
end as PlPosition
|
||||||
|
,sum(HDs) AS n
|
||||||
|
|
||||||
|
,to_char(round(100.0*sum(street0VPI)/sum(HDs)),'90D0') AS vpip
|
||||||
|
,to_char(round(100.0*sum(street0Aggr)/sum(HDs)),'90D0') AS pfr
|
||||||
|
,case when sum(stealattemptchance) = 0 then '0'
|
||||||
|
else to_char(100.0*sum(stealattempted)/sum(stealattemptchance),'90D0')
|
||||||
|
end AS steals
|
||||||
|
,to_char(round(100.0*sum(street1Seen)/sum(HDs)),'90D0') AS saw_f
|
||||||
|
,to_char(round(100.0*sum(sawShowdown)/sum(HDs)),'90D0') AS sawsd
|
||||||
|
,case when sum(street1Seen) = 0 then 'NA'
|
||||||
|
else to_char(round(100.0*sum(sawShowdown)/sum(street1Seen)),'90D0')
|
||||||
|
end AS wtsdwsf
|
||||||
|
,case when sum(sawShowdown) = 0 then 'NA'
|
||||||
|
else to_char(round(100.0*sum(wonAtSD)/sum(sawShowdown)),'90D0')
|
||||||
|
end AS wmsd
|
||||||
|
,case when sum(street1Seen) = 0 then 'NA'
|
||||||
|
else to_char(round(100.0*sum(street1Aggr)/sum(street1Seen)),'90D0')
|
||||||
|
end AS FlAFq
|
||||||
|
,case when sum(street2Seen) = 0 then 'NA'
|
||||||
|
else to_char(round(100.0*sum(street2Aggr)/sum(street2Seen)),'90D0')
|
||||||
|
end AS TuAFq
|
||||||
|
,case when sum(street3Seen) = 0 then 'NA'
|
||||||
|
else to_char(round(100.0*sum(street3Aggr)/sum(street3Seen)),'90D0')
|
||||||
|
end AS RvAFq
|
||||||
|
,case when sum(street1Seen)+sum(street2Seen)+sum(street3Seen) = 0 then 'NA'
|
||||||
|
else to_char(round(100.0*(sum(street1Aggr)+sum(street2Aggr)+sum(street3Aggr))
|
||||||
|
/(sum(street1Seen)+sum(street2Seen)+sum(street3Seen))),'90D0')
|
||||||
|
end AS PoFAFq
|
||||||
|
,to_char(sum(totalProfit)/100.0,'9G999G990D00') AS Net
|
||||||
|
,case when sum(HDs) = 0 then '0'
|
||||||
|
else to_char((sum(totalProfit)/(gt.bigBlind+0.0)) / (sum(HDs)/100.0), '990D00')
|
||||||
|
end AS BBper100
|
||||||
|
,case when sum(HDs) = 0 then '0'
|
||||||
|
else to_char( (sum(totalProfit)/100.0) / sum(HDs), '90D0000')
|
||||||
|
end AS Profitperhand
|
||||||
|
|
||||||
|
from Gametypes gt
|
||||||
|
inner join Sites s on (s.Id = gt.siteId)
|
||||||
|
inner join HudCache hc on (hc.gameTypeId = gt.Id)
|
||||||
|
where hc.playerId in <player_test>
|
||||||
|
/* use <gametype_test> here ? */
|
||||||
|
group by gt.base
|
||||||
|
,gt.category
|
||||||
|
,upper(gt.limitType)
|
||||||
|
,s.name
|
||||||
|
,gt.bigBlind
|
||||||
|
,hc.gametypeId
|
||||||
|
,PlPosition
|
||||||
|
) stats
|
||||||
|
inner join
|
||||||
|
( select /* profit from handsplayers/handsactions */
|
||||||
|
hprof.gameTypeId,
|
||||||
|
case when hprof.position = 'B' then -2
|
||||||
|
when hprof.position = 'S' then -1
|
||||||
|
when hprof.position in ('3','4') then 2
|
||||||
|
when hprof.position in ('6','7') then 5
|
||||||
|
else cast(hprof.position as smallint)
|
||||||
|
end as PlPosition,
|
||||||
|
sum(hprof.profit) as sum_profit,
|
||||||
|
avg(hprof.profit/100.0) as profitperhand,
|
||||||
|
variance(hprof.profit/100.0) as variance
|
||||||
|
from
|
||||||
|
(select hp.handId, h.gameTypeId, hp.position, 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
|
||||||
|
left 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, PlPosition
|
||||||
|
) hprof2
|
||||||
|
on ( hprof2.gameTypeId = stats.gameTypeId
|
||||||
|
and hprof2.PlPosition = stats.PlPosition)
|
||||||
|
order by stats.category, stats.limittype, stats.bigBlind, cast(stats.PlPosition as smallint)
|
||||||
"""
|
"""
|
||||||
elif(self.dbname == 'SQLite'):
|
elif(self.dbname == 'SQLite'):
|
||||||
self.query['playerStatsByPosition'] = """ """
|
self.query['playerStatsByPosition'] = """ """
|
||||||
|
@ -1131,8 +1221,8 @@ class FpdbSQLQueries:
|
||||||
variance(hprof.profit/100.0) as variance,
|
variance(hprof.profit/100.0) as variance,
|
||||||
count(*) as n
|
count(*) as n
|
||||||
from
|
from
|
||||||
(select hp.handId, h.gameTypeId, hp.position, hp.winnings, SUM(ha.amount)
|
(select hp.handId, h.gameTypeId, hp.position, hp.winnings, SUM(ha.amount) as costs
|
||||||
costs, hp.winnings - SUM(ha.amount) profit
|
, hp.winnings - SUM(ha.amount) as profit
|
||||||
from HandsPlayers hp
|
from HandsPlayers hp
|
||||||
inner join Hands h ON h.id = hp.handId
|
inner join Hands h ON h.id = hp.handId
|
||||||
left join HandsActions ha ON ha.handPlayerId = hp.id
|
left join HandsActions ha ON ha.handPlayerId = hp.id
|
||||||
|
|
|
@ -120,10 +120,11 @@ class GuiPositionalStats (threading.Thread):
|
||||||
nametest = nametest.replace(",)",")")
|
nametest = nametest.replace(",)",")")
|
||||||
|
|
||||||
tmp = tmp.replace("<player_test>", nametest)
|
tmp = tmp.replace("<player_test>", nametest)
|
||||||
|
#tmp = tmp.replace("<gametype_test>", "gt.id")
|
||||||
|
|
||||||
self.cursor.execute(tmp)
|
self.cursor.execute(tmp)
|
||||||
result = self.cursor.fetchall()
|
result = self.cursor.fetchall()
|
||||||
cols = 16
|
cols = 18
|
||||||
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)
|
||||||
|
@ -131,7 +132,7 @@ class GuiPositionalStats (threading.Thread):
|
||||||
vbox.add(self.stats_table)
|
vbox.add(self.stats_table)
|
||||||
|
|
||||||
# Create header row
|
# Create header row
|
||||||
titles = ("Game", "Position", "#", "VPIP", "PFR", "Saw_F", "SawSD", "WtSDwsF", "W$SD", "FlAFq", "TuAFq", "RvAFq", "PoFAFq", "Net($)", "BB/100", "$/hand", "Variance")
|
titles = ("Game", "Position", "#", "VPIP", "PFR", "Steals", "Saw_F", "SawSD", "WtSDwsF", "W$SD", "FlAFq", "TuAFq", "RvAFq", "PoFAFq", "Net($)", "BB/100", "$/hand", "Variance")
|
||||||
|
|
||||||
col = 0
|
col = 0
|
||||||
row = 0
|
row = 0
|
||||||
|
@ -155,6 +156,8 @@ class GuiPositionalStats (threading.Thread):
|
||||||
l = gtk.Label(' ')
|
l = gtk.Label(' ')
|
||||||
if col == 0:
|
if col == 0:
|
||||||
l.set_alignment(xalign=0.0, yalign=0.5)
|
l.set_alignment(xalign=0.0, yalign=0.5)
|
||||||
|
elif col == 1:
|
||||||
|
l.set_alignment(xalign=0.5, yalign=0.5)
|
||||||
else:
|
else:
|
||||||
l.set_alignment(xalign=1.0, yalign=0.5)
|
l.set_alignment(xalign=1.0, yalign=0.5)
|
||||||
eb.add(l)
|
eb.add(l)
|
||||||
|
|
Loading…
Reference in New Issue
Block a user