From ef060cd96a02a2ea2a68e90cf733aa756bcf794e Mon Sep 17 00:00:00 2001 From: sqlcoder Date: Sat, 13 Dec 2008 14:47:03 +0000 Subject: [PATCH] playerstats: refine mysql query to stop divide by zero errors and format figures properly --- pyfpdb/FpdbSQLQueries.py | 68 ++++++++++++++++++++++++++++------------ 1 file changed, 48 insertions(+), 20 deletions(-) diff --git a/pyfpdb/FpdbSQLQueries.py b/pyfpdb/FpdbSQLQueries.py index c9ed27fa..13899707 100644 --- a/pyfpdb/FpdbSQLQueries.py +++ b/pyfpdb/FpdbSQLQueries.py @@ -683,37 +683,65 @@ class FpdbSQLQueries: ,stats.FlAFq ,stats.TuAFq ,stats.RvAFq - ,stats.PFAFq - ,hprof2.sum_profit/100 as Net - ,(hprof2.sum_profit/stats.bigBlind)/(stats.n/100) as BBlPer100 - ,hprof2.profitperhand as Profitperhand + ,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 + */ ,hprof2.variance as Variance FROM - (select # stats from hudcache + (select /* stats from hudcache */ gt.base ,gt.category - ,upper(gt.limitType) limitType + ,upper(gt.limitType) as 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 + ,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 + ,case when sum(street1Seen) = 0 then 'oo' + else format(100.0*sum(sawShowdown)/sum(street1Seen),1) + end AS wtsdwsf + ,case when sum(sawShowdown) = 0 then 'oo' + else format(100.0*sum(wonAtSD)/sum(sawShowdown),1) + end AS wmsd + ,case when sum(street1Seen) = 0 then 'oo' + else format(100.0*sum(street1Aggr)/sum(street1Seen),1) + end AS FlAFq + ,case when sum(street2Seen) = 0 then 'oo' + else format(100.0*sum(street2Aggr)/sum(street2Seen),1) + end AS TuAFq + ,case when sum(street3Seen) = 0 then 'oo' + else format(100.0*sum(street3Aggr)/sum(street3Seen),1) + end AS RvAFq + ,case when sum(street1Seen)+sum(street2Seen)+sum(street3Seen) = 0 then 'oo' + else format(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 + ,format((sum(totalProfit)/(gt.bigBlind+0.0)) / (sum(HDs)/100.0),2) + AS BBper100 + ,format( (sum(totalProfit)/100.0) / sum(HDs), 4) 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 hc.gametypeId + group by gt.base + ,gt.category + ,upper(gt.limitType) + ,s.name + ,gt.bigBlind + ,hc.gametypeId ) stats inner join ( select # profit from handsplayers/handsactions @@ -734,7 +762,7 @@ class FpdbSQLQueries: group by hprof.gameTypeId ) hprof2 on hprof2.gameTypeId = stats.gameTypeId - order by stats.base, stats.limittype, stats.bigBlind""" + order by stats.category, stats.limittype, stats.bigBlind""" elif(self.dbname == 'PostgreSQL'): self.query['playerStats'] = """ SELECT upper(stats.limitType) || ' '