diff --git a/pyfpdb/FpdbSQLQueries.py b/pyfpdb/FpdbSQLQueries.py index 55d56650..c905170e 100644 --- a/pyfpdb/FpdbSQLQueries.py +++ b/pyfpdb/FpdbSQLQueries.py @@ -670,13 +670,13 @@ class FpdbSQLQueries: ,gt.bigBlind ,hc.gametypeId ,sum(HDs) AS n - ,format(100.0*sum(street0VPI)/sum(HDs),1) AS vpip - ,format(100.0*sum(street0Aggr)/sum(HDs),1) AS pfr + ,format(100.0*sum(street0VPI)/sum(HDs),1) AS vpip + ,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(sawShowdown)/sum(HDs),1) AS sawsd + ,format(100.0*sum(street1Seen)/sum(HDs),1) AS saw_f + ,format(100.0*sum(sawShowdown)/sum(HDs),1) AS sawsd ,case when sum(street1Seen) = 0 then 'oo' else format(100.0*sum(sawShowdown)/sum(street1Seen),1) end AS wtsdwsf @@ -718,8 +718,8 @@ class FpdbSQLQueries: avg(hprof.profit/100.0) profitperhand, variance(hprof.profit/100.0) variance from - (select hp.handId, h.gameTypeId, hp.winnings, SUM(ha.amount) - costs, hp.winnings - SUM(ha.amount) profit + (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 left join HandsActions ha ON ha.handPlayerId = hp.id @@ -860,6 +860,7 @@ class FpdbSQLQueries: ,stats.n ,stats.vpip ,stats.pfr + ,stats.steals ,stats.saw_f ,stats.sawsd ,stats.wtsdwsf @@ -896,10 +897,13 @@ class FpdbSQLQueries: else 9 end as PlPosition ,sum(HDs) AS n - ,format(100.0*sum(street0VPI)/sum(HDs),1) AS vpip - ,format(100.0*sum(street0Aggr)/sum(HDs),1) AS pfr - ,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(street0VPI)/sum(HDs),1) AS vpip + ,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(sawShowdown)/sum(HDs),1) AS sawsd ,case when sum(street1Seen) = 0 then 'oo' else format(100.0*sum(sawShowdown)/sum(street1Seen),1) end AS wtsdwsf @@ -949,8 +953,8 @@ class FpdbSQLQueries: 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) - costs, hp.winnings - SUM(ha.amount) profit + (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 @@ -968,52 +972,138 @@ class FpdbSQLQueries: elif(self.dbname == 'PostgreSQL'): self.query['playerStatsByPosition'] = """ select /* stats from hudcache */ - hc.position AS pl_position - ,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 - ,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 'oo' - else to_char(round(100.0*sum(sawShowdown)/sum(street1Seen)),'90D0') - end AS wtsdwsf - ,case when sum(sawShowdown) = 0 then 'oo' - else to_char(round(100.0*sum(wonAtSD)/sum(sawShowdown)),'90D0') - end AS wmsd - ,case when sum(street1Seen) = 0 then 'oo' - else to_char(round(100.0*sum(street1Aggr)/sum(street1Seen)),'90D0') - end AS FlAFq - ,case when sum(street2Seen) = 0 then 'oo' - else to_char(round(100.0*sum(street2Aggr)/sum(street2Seen)),'90D0') - end AS TuAFq - ,case when sum(street3Seen) = 0 then 'oo' - else to_char(round(100.0*sum(street3Aggr)/sum(street3Seen)),'90D0') - end AS RvAFq - ,case when sum(street1Seen)+sum(street2Seen)+sum(street3Seen) = 0 then 'oo' - 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 'oo' - else to_char((sum(totalProfit)/(gt.bigBlind+0.0)) / (sum(HDs)/100.0), '990D00') - end AS BBper100 - from Gametypes gt - inner join Sites s on (s.Id = gt.siteId) - inner join HudCache hc on (hc.gameTypeId = gt.Id) - inner join Players p on (p.id = hc.playerId) - where hc.playerId in - and gt.type = 'ring' - and gt.id = /* must specify gametypeid */ - /* and stats.n > 100 optional stat-based queries */ - group by pl_position, gt.bigblind - order by case when hc.position = 'B' then -2 - when hc.position = 'S' then -1 - when hc.position = 'D' then 0 - when hc.position = 'C' then 1 - when hc.position = 'M' then 2 - when hc.position = 'E' then 5 - else 9 - end + upper(stats.limitType) || ' ' + || upper(substr(stats.category,1,1)) || substr(stats.category,2) || ' ' + || stats.name || ' $' + || trim(leading ' ' from + case when stats.bigBlind < 100 + then to_char(stats.bigBlind/100.0,'90D00') + else to_char(stats.bigBlind/100.0,'999990') + end ) AS Game + ,case when stats.PlPosition = -2 then 'BB' + when stats.PlPosition = -1 then 'SB' + when stats.PlPosition = 0 then 'Btn' + when stats.PlPosition = 1 then 'CO' + when stats.PlPosition = 2 then 'MP' + when stats.PlPosition = 5 then 'EP' + else '??' + end AS PlPosition + ,stats.n + ,stats.vpip + ,stats.pfr + ,stats.steals + ,stats.saw_f + ,stats.sawsd + ,stats.wtsdwsf + ,stats.wmsd + ,stats.FlAFq + ,stats.TuAFq + ,stats.RvAFq + ,stats.PoFAFq + /* if you have handsactions data the next 3 fields should give same answer as + following 3 commented out fields */ + ,stats.Net + ,stats.BBper100 + ,stats.Profitperhand + /*,format(hprof2.sum_profit/100.0,2) AS Net + ,format((hprof2.sum_profit/(stats.bigBlind+0.0)) / (stats.n/100.0),2) + AS BBlPer100 + ,hprof2.profitperhand AS Profitperhand + */ + ,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 = 'D' then 0 + when hc.position = 'C' then 1 + when hc.position = 'M' then 2 + when hc.position = 'E' then 5 + else 9 + 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 + /* use 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 + /* use 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'): self.query['playerStatsByPosition'] = """ """ @@ -1131,8 +1221,8 @@ class FpdbSQLQueries: variance(hprof.profit/100.0) as variance, count(*) as n from - (select hp.handId, h.gameTypeId, hp.position, hp.winnings, SUM(ha.amount) - costs, hp.winnings - SUM(ha.amount) profit + (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 diff --git a/pyfpdb/GuiPositionalStats.py b/pyfpdb/GuiPositionalStats.py index 587742a3..5e9d1d71 100644 --- a/pyfpdb/GuiPositionalStats.py +++ b/pyfpdb/GuiPositionalStats.py @@ -120,10 +120,11 @@ class GuiPositionalStats (threading.Thread): nametest = nametest.replace(",)",")") tmp = tmp.replace("", nametest) + #tmp = tmp.replace("", "gt.id") self.cursor.execute(tmp) result = self.cursor.fetchall() - cols = 16 + cols = 18 rows = len(result)+1 # +1 for title row self.stats_table = gtk.Table(rows, cols, False) self.stats_table.set_col_spacings(4) @@ -131,7 +132,7 @@ class GuiPositionalStats (threading.Thread): vbox.add(self.stats_table) # 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 row = 0 @@ -155,6 +156,8 @@ class GuiPositionalStats (threading.Thread): l = gtk.Label(' ') if col == 0: l.set_alignment(xalign=0.0, yalign=0.5) + elif col == 1: + l.set_alignment(xalign=0.5, yalign=0.5) else: l.set_alignment(xalign=1.0, yalign=0.5) eb.add(l)