update mysql query for position stats (postgres one still to do ...)

This commit is contained in:
sqlcoder 2008-12-15 23:15:54 +00:00
parent f1be7c2ec0
commit 695b3a53cf

View File

@ -867,53 +867,130 @@ class FpdbSQLQueries:
if(self.dbname == 'MySQL InnoDB'): if(self.dbname == 'MySQL InnoDB'):
self.query['playerStatsByPosition'] = """ self.query['playerStatsByPosition'] = """
select /* stats from hudcache */ SELECT
hc.position concat(upper(stats.limitType), ' '
,sum(HDs) as n ,concat(upper(substring(stats.category,1,1)),substring(stats.category,2) ), ' '
,format(round(100.0*sum(street0VPI)/sum(HDs)),1) AS vpip ,stats.name, ' $'
,format(round(100.0*sum(street0Aggr)/sum(HDs)),1) AS pfr ,cast(trim(leading ' ' from
,format(round(100.0*sum(street1Seen)/sum(HDs)),1) AS saw_f case when stats.bigBlind < 100 then format(stats.bigBlind/100.0,2)
,format(round(100.0*sum(sawShowdown)/sum(HDs)),1) AS sawsd else format(stats.bigBlind/100.0,0)
,case when sum(street1Seen) = 0 then 'oo' end ) as char)
else format(round(100.0*sum(sawShowdown)/sum(street1Seen)),1) ) 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 format(round(100.0*sum(wonAtSD)/sum(sawShowdown)),1) 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 format(round(100.0*sum(street1Aggr)/sum(street1Seen)),1) when stats.PlPosition = 5 then 'EP'
end AS FlAFq else '??'
,case when sum(street2Seen) = 0 then 'oo' end AS PlPosition
else format(round(100.0*sum(street2Aggr)/sum(street2Seen)),1) ,stats.n
end AS TuAFq ,stats.vpip
,case when sum(street3Seen) = 0 then 'oo' ,stats.pfr
else format(round(100.0*sum(street3Aggr)/sum(street3Seen)),1) ,stats.saw_f
end AS RvAFq ,stats.sawsd
,case when sum(street1Seen)+sum(street2Seen)+sum(street3Seen) = 0 then 'oo' ,stats.wtsdwsf
else format(round(100.0*(sum(street1Aggr)+sum(street2Aggr)+sum(street3Aggr)) ,stats.wmsd
/(sum(street1Seen)+sum(street2Seen)+sum(street3Seen))),1) ,stats.FlAFq
end AS PoFAFq ,stats.TuAFq
,format(sum(totalProfit)/100.0,2) AS Net ,stats.RvAFq
,case when sum(HDs) = 0 then 'oo' ,stats.PoFAFq
else format((sum(totalProfit)/(gt.bigBlind+0.0)) / (sum(HDs)/100.0),2) /* if you have handsactions data the next 3 fields should give same answer as
end AS BBper100 following 3 commented out fields */
from Gametypes gt ,stats.Net
inner join Sites s on (s.Id = gt.siteId) ,stats.BBper100
inner join HudCache hc on (hc.gameTypeId = gt.Id) ,stats.Profitperhand
inner join Players p on (p.id = hc.playerId) /*,format(hprof2.sum_profit/100.0,2) AS Net
where hc.playerId in <player_test> ,format((hprof2.sum_profit/(stats.bigBlind+0.0)) / (stats.n/100.0),2)
and gt.type = 'ring' AS BBlPer100
and gt.id = <gametype_test> /* must specify gametypeid */ ,hprof2.profitperhand AS Profitperhand
/* and stats.n > 100 optional stat-based queries */ */
group by hc.position, gt.bigBlind ,format(hprof2.variance,2) AS Variance
order by case when hc.position = 'B' then -2 FROM
when hc.position = 'S' then -1 (select /* stats from hudcache */
when hc.position = 'D' then 0 gt.base
when hc.position = 'C' then 1 ,gt.category
when hc.position = 'M' then 2 ,upper(gt.limitType) as limitType
when hc.position = 'E' then 5 ,s.name
else 9 ,gt.bigBlind
end ,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
,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 <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 hprof.position
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)
costs, hp.winnings - SUM(ha.amount) 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 signed)
""" """
elif(self.dbname == 'PostgreSQL'): elif(self.dbname == 'PostgreSQL'):
self.query['playerStatsByPosition'] = """ self.query['playerStatsByPosition'] = """