revise position stats query using hudcache data and create postgres version

This commit is contained in:
sqlcoder 2008-12-13 03:17:54 +00:00
parent cb2e8a96ef
commit f51d760a54

View File

@ -776,97 +776,104 @@ class FpdbSQLQueries:
if(self.dbname == 'MySQL InnoDB'): if(self.dbname == 'MySQL InnoDB'):
self.query['playerStatsByPosition'] = """ self.query['playerStatsByPosition'] = """
SELECT stats.gametypeId select /* stats from hudcache */
,stats.base hc.position
,stats.limitType ,sum(HDs) as n
,stats.name ,format(round(100.0*sum(street0VPI)/sum(HDs)),1) AS vpip
,format(stats.bigBlind/100,2) as BigBlind ,format(round(100.0*sum(street0Aggr)/sum(HDs)),1) AS pfr
,p.name ,format(round(100.0*sum(street1Seen)/sum(HDs)),1) AS saw_f
,stats.pl_position ,format(round(100.0*sum(sawShowdown)/sum(HDs)),1) AS sawsd
,stats.n ,case when sum(street1Seen) = 0 then 'oo'
,stats.vpip else format(round(100.0*sum(sawShowdown)/sum(street1Seen)),1)
,stats.pfr end AS wtsdwsf
,stats.saw_f ,case when sum(sawShowdown) = 0 then 'oo'
,stats.sawsd else format(round(100.0*sum(wonAtSD)/sum(sawShowdown)),1)
,stats.wtsdwsf end AS wmsd
,stats.wmsd ,case when sum(street1Seen) = 0 then 'oo'
,stats.FlAFq else format(round(100.0*sum(street1Aggr)/sum(street1Seen)),1)
,stats.TuAFq end AS FlAFq
,stats.RvAFq ,case when sum(street2Seen) = 0 then 'oo'
,stats.PFAFq else format(round(100.0*sum(street2Aggr)/sum(street2Seen)),1)
,hprof2.sum_profit/100 as Net end AS TuAFq
,(hprof2.sum_profit/stats.bigBlind)/(stats.n/100) as BBlPer100 ,case when sum(street3Seen) = 0 then 'oo'
# ... any other stats you want to add else format(round(100.0*sum(street3Aggr)/sum(street3Seen)),1)
FROM end AS RvAFq
(select # stats from hudcache ,case when sum(street1Seen)+sum(street2Seen)+sum(street3Seen) = 0 then 'oo'
hc.playerId else format(round(100.0*(sum(street1Aggr)+sum(street2Aggr)+sum(street3Aggr))
,gt.base /(sum(street1Seen)+sum(street2Seen)+sum(street3Seen))),1)
,upper(gt.limitType) as limitType end AS PoFAFq
,s.name ,format(sum(totalProfit)/100.0,2) AS Net
,gt.bigBlind ,case when sum(HDs) = 0 then 'oo'
,hc.gametypeId else format((sum(totalProfit)/(gt.bigBlind+0.0)) / (sum(HDs)/100.0),2)
,case when hc.position = 'B' then -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 <player_test>
and gt.type = 'ring'
and gt.id = <gametype_test> /* must specify gametypeid */
/* and stats.n > 100 optional stat-based queries */
group by hc.position, gt.bigBlind
order by 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 as pl_position end
"""
elif(self.dbname == 'PostgreSQL'):
self.query['playerStatsByPosition'] = """
select /* stats from hudcache */
hc.position AS pl_position
,sum(HDs) as n ,sum(HDs) as n
,round(100*sum(street0VPI)/sum(HDs)) as vpip ,to_char(round(100.0*sum(street0VPI)/sum(HDs)),'90D0') AS vpip
,round(100*sum(street0Aggr)/sum(HDs)) as pfr ,to_char(round(100.0*sum(street0Aggr)/sum(HDs)),'90D0') AS pfr
,round(100*sum(street1Seen)/sum(HDs)) AS saw_f ,to_char(round(100.0*sum(street1Seen)/sum(HDs)),'90D0') AS saw_f
,round(100*sum(sawShowdown)/sum(HDs)) AS sawsd ,to_char(round(100.0*sum(sawShowdown)/sum(HDs)),'90D0') AS sawsd
,round(100*sum(sawShowdown)/sum(street1Seen)) AS wtsdwsf ,case when sum(street1Seen) = 0 then 'oo'
,round(100*sum(wonAtSD)/sum(sawShowdown)) AS wmsd else to_char(round(100.0*sum(sawShowdown)/sum(street1Seen)),'90D0')
,round(100*sum(street1Aggr)/sum(street1Seen)) AS FlAFq end AS wtsdwsf
,round(100*sum(street2Aggr)/sum(street2Seen)) AS TuAFq ,case when sum(sawShowdown) = 0 then 'oo'
,round(100*sum(street3Aggr)/sum(street3Seen)) AS RvAFq else to_char(round(100.0*sum(wonAtSD)/sum(sawShowdown)),'90D0')
,round(100*(sum(street1Aggr)+sum(street2Aggr)+sum(street3Aggr)) end AS wmsd
/(sum(street1Seen)+sum(street2Seen)+sum(street3Seen))) AS PFAFq ,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 from Gametypes gt
inner join Sites s on (s.Id = gt.siteId) inner join Sites s on (s.Id = gt.siteId)
inner join HudCache hc on (hc.gameTypeId = gt.Id) inner join HudCache hc on (hc.gameTypeId = gt.Id)
where gt.limittype = 'nl' inner join Players p on (p.id = hc.playerId)
and hc.playerId in (3) # always specify player for position stats where hc.playerId in <player_test>
# use <gametype_test> here and gt.type = 'ring'
# use <activeseats_test> here and gt.id = <gametype_test> /* must specify gametypeid */
group by hc.playerId, hc.gametypeId, pl_position /* and stats.n > 100 optional stat-based queries */
) stats group by pl_position, gt.bigblind
inner join order by case when hc.position = 'B' then -2
( select # profit from handsplayers/handsactions when hc.position = 'S' then -1
hprof.playerId when hc.position = 'D' then 0
, hprof.gameTypeId when hc.position = 'C' then 1
, case when hprof.position = 'B' then -2 when hc.position = 'M' then 2
when hprof.position = 'S' then -1 when hc.position = 'E' then 5
when hprof.position in ('3','4') then 2 else 9
when hprof.position in ('6','7') then 5 end
else hprof.position
end as pl_position
, sum(hprof.profit) as sum_profit
from
(select hp.playerId, hp.handId, h.gameTypeId, hp.position, 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 (3) # always specify player for position stats
# use <gametype_test> here
# use <activeseats_test> here
and hp.tourneysPlayersId IS NULL
group by hp.playerId, hp.handId, h.gameTypeId, hp.position, hp.winnings
) hprof
group by hprof.playerId, hprof.gameTypeId, pl_position
) hprof2
on ( hprof2.gameTypeId = stats.gameTypeId
and hprof2.pl_position = stats.pl_position)
inner join Players p on (p.id = stats.playerId)
where 1 = 1
order by stats.base, stats.limittype, stats.bigBlind, stats.pl_position, BBlPer100 desc
""" """
elif(self.dbname == 'PostgreSQL'):
self.query['playerStatsByPosition'] = """ """
elif(self.dbname == 'SQLite'): elif(self.dbname == 'SQLite'):
self.query['playerStatsByPosition'] = """ """ self.query['playerStatsByPosition'] = """ """