From cb2e8a96ef4d53f650f6ae122127f9de84a9ef9e Mon Sep 17 00:00:00 2001 From: sqlcoder Date: Sat, 13 Dec 2008 02:18:02 +0000 Subject: [PATCH] use hudcache query for all player stats and tidy up output --- pyfpdb/FpdbSQLQueries.py | 177 ++++++++++++++++++++++++--------------- pyfpdb/GuiPlayerStats.py | 12 ++- 2 files changed, 118 insertions(+), 71 deletions(-) diff --git a/pyfpdb/FpdbSQLQueries.py b/pyfpdb/FpdbSQLQueries.py index 4b854f0f..8f2d4d68 100644 --- a/pyfpdb/FpdbSQLQueries.py +++ b/pyfpdb/FpdbSQLQueries.py @@ -637,7 +637,8 @@ class FpdbSQLQueries: if(self.dbname == 'MySQL InnoDB') or (self.dbname == 'PostgreSQL'): self.query['getRingProfitAllHandsPlayerIdSite'] = """ - SELECT hp.handId, hp.winnings, SUM(ha.amount), hp.winnings - SUM(ha.amount) + SELECT hp.handId, hp.winnings, coalesce(hp.ante,0) + SUM(ha.amount) + , hp.winnings - (coalesce(hp.ante,0) + SUM(ha.amount)) FROM HandsPlayers hp INNER JOIN Players pl ON hp.playerId = pl.id INNER JOIN Hands h ON h.id = hp.handId @@ -645,7 +646,7 @@ class FpdbSQLQueries: WHERE pl.name = %s AND pl.siteId = %s AND hp.tourneysPlayersId IS NULL - GROUP BY hp.handId, hp.winnings, h.handStart + GROUP BY hp.handId, hp.winnings, h.handStart, hp.ante ORDER BY h.handStart""" elif(self.dbname == 'SQLite'): #Probably doesn't work. @@ -662,72 +663,114 @@ class FpdbSQLQueries: ORDER BY h.handStart""" if(self.dbname == 'MySQL InnoDB'): - self.query['playerStats'] = """ - SELECT stats.gametypeId - ,stats.base - ,stats.limitType - ,stats.name - ,format(stats.bigBlind/100,2) as BigBlind - ,stats.n - ,stats.vpip - ,stats.pfr - ,stats.saw_f - ,stats.sawsd - ,stats.wtsdwsf - ,stats.wmsd - ,stats.FlAFq - ,stats.TuAFq - ,stats.RvAFq - ,stats.PFAFq - ,hprof2.sum_profit/100 as Net - ,(hprof2.sum_profit/stats.bigBlind)/(stats.n/100) as BBlPer100 - FROM - (select # stats from hudcache - gt.base - ,upper(gt.limitType) limitType - ,s.name - ,gt.bigBlind - ,hc.gametypeId - ,sum(HDs) as n - ,round(100*sum(street0VPI)/sum(HDs)) as vpip - ,round(100*sum(street0Aggr)/sum(HDs)) as pfr - ,round(100*sum(street1Seen)/sum(HDs)) AS saw_f - ,round(100*sum(sawShowdown)/sum(HDs)) AS sawsd - ,round(100*sum(sawShowdown)/sum(street1Seen)) AS wtsdwsf - ,round(100*sum(wonAtSD)/sum(sawShowdown)) AS wmsd - ,round(100*sum(street1Aggr)/sum(street1Seen)) AS FlAFq - ,round(100*sum(street2Aggr)/sum(street2Seen)) AS TuAFq - ,round(100*sum(street3Aggr)/sum(street3Seen)) AS RvAFq - ,round(100*(sum(street1Aggr)+sum(street2Aggr)+sum(street3Aggr)) - /(sum(street1Seen)+sum(street2Seen)+sum(street3Seen))) AS PFAFq - 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 hc.gametypeId - ) stats - inner join - ( select # profit from handsplayers/handsactions - hprof.gameTypeId, sum(hprof.profit) sum_profit - from - (select hp.handId, h.gameTypeId, hp.winnings, - coalesce(hp.ante,0) + SUM(ha.amount) costs, - hp.winnings - (coalesce(hp.ante,0) + 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 - # use 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""" + self.query['playerStats'] = """ /* format(stats.bigBlind/100,2) as BigBlind */ + select /* stats from hudcache */ + concat(upper(gt.limitType), ' ' + ,concat(upper(substring(gt.category,1,1)),substring(gt.category,2) ), ' ' + ,s.name, ' $' /* limittype category site $Bigbl in one field? */ + ,cast(trim(leading ' ' from + case when gt.bigBlind < 100 then format(gt.bigBlind/100.0,2) + else format(gt.bigBlind/100.0,0) + end ) as char) + ) AS Game + ,sum(HDs) as n + ,format(round(100.0*sum(street0VPI)/sum(HDs)),1) AS vpip + ,format(round(100.0*sum(street0Aggr)/sum(HDs)),1) AS pfr + ,format(round(100.0*sum(street1Seen)/sum(HDs)),1) AS saw_f + ,format(round(100.0*sum(sawShowdown)/sum(HDs)),1) AS sawsd + ,case when sum(street1Seen) = 0 then 'oo' + else format(round(100.0*sum(sawShowdown)/sum(street1Seen)),1) + end AS wtsdwsf + ,case when sum(sawShowdown) = 0 then 'oo' + else format(round(100.0*sum(wonAtSD)/sum(sawShowdown)),1) + end AS wmsd + ,case when sum(street1Seen) = 0 then 'oo' + else format(round(100.0*sum(street1Aggr)/sum(street1Seen)),1) + end AS FlAFq + ,case when sum(street2Seen) = 0 then 'oo' + else format(round(100.0*sum(street2Aggr)/sum(street2Seen)),1) + end AS TuAFq + ,case when sum(street3Seen) = 0 then 'oo' + else format(round(100.0*sum(street3Aggr)/sum(street3Seen)),1) + end AS RvAFq + ,case when sum(street1Seen)+sum(street2Seen)+sum(street3Seen) = 0 then 'oo' + else format(round(100.0*(sum(street1Aggr)+sum(street2Aggr)+sum(street3Aggr)) + /(sum(street1Seen)+sum(street2Seen)+sum(street3Seen))),1) + end AS PoFAFq + ,format(sum(totalProfit)/100.0,2) AS Net + ,case when sum(HDs) = 0 then 'oo' + else format((sum(totalProfit)/(gt.bigBlind+0.0)) / (sum(HDs)/100.0),2) + 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 + /* use here ? */ + -- and stats.n > 100 /* optional stat-based queries */ + and gt.type = 'ring' + -- and stats.gametypeId = 5 + -- and p.name = 'xyz' /* could add player_name query here */ + group by gt.category + ,gt.limitType + ,s.name + ,gt.bigBlind + ,hc.gametypeId + order by gt.category, gt.limittype, gt.bigBlind""" elif(self.dbname == 'PostgreSQL'): - self.query['playerStats'] = """ """ + self.query['playerStats'] = """ + select /* stats from hudcache */ + upper(gt.limitType) || ' ' + || initcap(gt.category) || ' ' + || s.name || ' $' /* limittype category site $Bigbl in one field? */ + || trim(leading ' ' from + case when gt.bigBlind < 100 then to_char(gt.bigBlind/100.0,'0D00') + else to_char(gt.bigBlind/100.0,'99990') + end ) AS Game + ,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 + /* use here ? */ + -- and stats.n > 100 /* optional stat-based queries */ + and gt.type = 'ring' + -- and stats.gametypeId = 5 + -- and p.name = 'xyz' /* could add player_name query here */ + group by gt.category + ,gt.limitType + ,s.name + ,gt.bigBlind + ,hc.gametypeId + order by gt.category, gt.limittype, gt.bigBlind""" elif(self.dbname == 'SQLite'): self.query['playerStats'] = """ """ diff --git a/pyfpdb/GuiPlayerStats.py b/pyfpdb/GuiPlayerStats.py index 7d689228..7e7d52bc 100644 --- a/pyfpdb/GuiPlayerStats.py +++ b/pyfpdb/GuiPlayerStats.py @@ -44,13 +44,13 @@ class GuiPlayerStats (threading.Thread): # Get currently active site and grab playerid tmp = self.sql.query['playerStats'] - result = self.cursor.execute(self.sql.query['getPlayerId'], self.heroes[self.activesite]) + result = self.cursor.execute(self.sql.query['getPlayerId'], (self.heroes[self.activesite],)) result = self.db.cursor.fetchall() pid = result[0][0] tmp = tmp.replace("", "(" + str(pid) + ")") self.cursor.execute(tmp) result = self.db.cursor.fetchall() - cols = 18 + cols = 14 rows = len(result)+1 # +1 for title row self.stats_table = gtk.Table(rows, cols, False) self.stats_table.set_col_spacings(4) @@ -58,7 +58,7 @@ class GuiPlayerStats (threading.Thread): vbox.add(self.stats_table) # Create header row - titles = ("GID", "base", "Style", "Site", "$BB", "Hands", "VPIP", "PFR", "saw_f", "sawsd", "wtsdwsf", "wmsd", "FlAFq", "TuAFq", "RvAFq", "PFAFq", "Net($)", "BB/100") + titles = ("Game", "Hands", "VPIP", "PFR", "Saw_F", "SawSD", "WtSDwsF", "W$SD", "FlAFq", "TuAFq", "RvAFq", "PFAFq", "Net($)", "BBl/100") col = 0 row = 0 @@ -76,7 +76,11 @@ class GuiPlayerStats (threading.Thread): bgcolor = "lightgrey" eb = gtk.EventBox() eb.modify_bg(gtk.STATE_NORMAL, gtk.gdk.color_parse(bgcolor)) - l = gtk.Label(result[row-1][col]) + l = gtk.Label(result[row][col]) + if col == 0: + l.set_alignment(xalign=0.0, yalign=0.5) + else: + l.set_alignment(xalign=1.0, yalign=0.5) eb.add(l) self.stats_table.attach(eb, col, col+1, row+1, row+2) l.show()