Merge branch 'master' of git://github.com/sqlcoder/fpdb-sql

This commit is contained in:
Matt Turnbull 2008-12-14 22:09:17 +00:00
commit 2796a95669
7 changed files with 1127 additions and 752 deletions

View File

@ -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.
@ -663,11 +664,15 @@ class FpdbSQLQueries:
if(self.dbname == 'MySQL InnoDB'):
self.query['playerStats'] = """
SELECT stats.gametypeId
,stats.base
,stats.limitType
,stats.name
,format(stats.bigBlind/100,2) as BigBlind
SELECT
concat(upper(stats.limitType), ' '
,concat(upper(substring(stats.category,1,1)),substring(stats.category,2) ), ' '
,stats.name, ' $'
,cast(trim(leading ' ' from
case when stats.bigBlind < 100 then format(stats.bigBlind/100.0,2)
else format(stats.bigBlind/100.0,0)
end ) as char)
) AS Game
,stats.n
,stats.vpip
,stats.pfr
@ -678,44 +683,77 @@ 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
,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
*/
,format(hprof2.variance,2) AS Variance
FROM
(select # stats from hudcache
(select /* stats from hudcache */
gt.base
,upper(gt.limitType) limitType
,gt.category
,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 <player_test>
# use <gametype_test> 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
hprof.gameTypeId, sum(hprof.profit) sum_profit
hprof.gameTypeId, sum(hprof.profit) sum_profit,
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
from HandsPlayers hp
inner join Hands h ON h.id = hp.handId
inner join HandsActions ha ON ha.handPlayerId = hp.id
left join HandsActions ha ON ha.handPlayerId = hp.id
where hp.playerId in <player_test>
# use <gametype_test> here ?
and hp.tourneysPlayersId IS NULL
@ -724,14 +762,16 @@ 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 stats.gametypeId
,stats.base
,stats.limitType
,stats.name
,(stats.bigBlind/100) as BigBlind
SELECT upper(stats.limitType) || ' '
|| initcap(stats.category) || ' '
|| stats.name || ' $'
|| trim(leading ' ' from
case when stats.bigBlind < 100 then to_char(stats.bigBlind/100.0,'0D00')
else to_char(stats.bigBlind/100.0,'99990')
end ) AS Game
,stats.n
,stats.vpip
,stats.pfr
@ -742,39 +782,69 @@ 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
,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
/*,to_char(hprof2.sum_profit/100.0,'9G999G990D00') AS Net
,to_char((hprof2.sum_profit/(stats.bigBlind+0.0)) / (stats.n/100.0), '990D00')
AS BBper100
,hprof2.profitperhand AS Profitperhand
*/
,round(hprof2.variance,2) AS Variance
FROM
(select gt.base
,gt.category
,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
,to_char(100.0*sum(street0VPI)/sum(HDs),'90D0') AS vpip
,to_char(100.0*sum(street0Aggr)/sum(HDs),'90D0') AS pfr
,to_char(100.0*sum(street1Seen)/sum(HDs),'90D0') AS saw_f
,to_char(100.0*sum(sawShowdown)/sum(HDs),'90D0') AS sawsd
,case when sum(street1Seen) = 0 then 'oo'
else to_char(100.0*sum(sawShowdown)/sum(street1Seen),'90D0')
end AS wtsdwsf
,case when sum(sawShowdown) = 0 then 'oo'
else to_char(100.0*sum(wonAtSD)/sum(sawShowdown),'90D0')
end AS wmsd
,case when sum(street1Seen) = 0 then 'oo'
else to_char(100.0*sum(street1Aggr)/sum(street1Seen),'90D0')
end AS FlAFq
,case when sum(street2Seen) = 0 then 'oo'
else to_char(100.0*sum(street2Aggr)/sum(street2Seen),'90D0')
end AS TuAFq
,case when sum(street3Seen) = 0 then 'oo'
else to_char(100.0*sum(street3Aggr)/sum(street3Seen),'90D0')
end AS RvAFq
,case when sum(street1Seen)+sum(street2Seen)+sum(street3Seen) = 0 then 'oo'
else to_char(100.0*(sum(street1Aggr)+sum(street2Aggr)+sum(street3Aggr))
/(sum(street1Seen)+sum(street2Seen)+sum(street3Seen)),'90D0')
end AS PoFAFq
,round(sum(totalProfit)/100.0,2) AS Net
,to_char((sum(totalProfit)/(gt.bigBlind+0.0)) / (sum(HDs)/100.0), '990D00')
AS BBper100
,to_char(sum(totalProfit/100.0) / (sum(HDs)+0.0), '990D0000') 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>
group by gt.base
,gt.category
,upper(gt.limitType)
,s.name
,gt.bigBlind
,hc.gametypeId
) stats
inner join
( select hprof.gameTypeId, sum(hprof.profit) as sum_profit
( select
hprof.gameTypeId, 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,
@ -782,8 +852,8 @@ class FpdbSQLQueries:
SUM(ha.amount) as costs,
hp.winnings - SUM(ha.amount) as profit
from HandsPlayers hp
inner join Hands h ON h.id = hp.handId
inner join HandsActions ha ON ha.handPlayerId = hp.id
inner join Hands h ON (h.id = hp.handId)
left join HandsActions ha ON (ha.handPlayerId = hp.id)
where hp.playerId in <player_test>
and hp.tourneysPlayersId IS NULL
group by hp.handId, h.gameTypeId, hp.position, hp.winnings
@ -797,97 +867,104 @@ class FpdbSQLQueries:
if(self.dbname == 'MySQL InnoDB'):
self.query['playerStatsByPosition'] = """
SELECT stats.gametypeId
,stats.base
,stats.limitType
,stats.name
,format(stats.bigBlind/100,2) as BigBlind
,p.name
,stats.pl_position
,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
# ... any other stats you want to add
FROM
(select # stats from hudcache
hc.playerId
,gt.base
,upper(gt.limitType) as limitType
,s.name
,gt.bigBlind
,hc.gametypeId
,case when hc.position = 'B' then -2
select /* stats from hudcache */
hc.position
,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 <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 = '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 pl_position
end
"""
elif(self.dbname == 'PostgreSQL'):
self.query['playerStatsByPosition'] = """
select /* stats from hudcache */
hc.position AS pl_position
,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
,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)
where gt.limittype = 'nl'
and hc.playerId in (3) # always specify player for position stats
# use <gametype_test> here
# use <activeseats_test> here
group by hc.playerId, hc.gametypeId, pl_position
) stats
inner join
( select # profit from handsplayers/handsactions
hprof.playerId
, 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 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
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 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
"""
elif(self.dbname == 'PostgreSQL'):
self.query['playerStatsByPosition'] = """ """
elif(self.dbname == 'SQLite'):
self.query['playerStatsByPosition'] = """ """

View File

@ -47,11 +47,12 @@ class GuiPlayerStats (threading.Thread):
result = self.cursor.execute(self.sql.query['getPlayerId'], (self.heroes[self.activesite],))
result = self.db.cursor.fetchall()
if not result == ():
pid = result[0][0]
pid = result[0][0]
tmp = tmp.replace("<player_test>", "(" + str(pid) + ")")
self.cursor.execute(tmp)
result = self.db.cursor.fetchall()
cols = 18
cols = 16
rows = len(result)+1 # +1 for title row
self.stats_table = gtk.Table(rows, cols, False)
self.stats_table.set_col_spacings(4)
@ -59,7 +60,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", "PoFAFq", "Net($)", "BB/100", "$/hand", "Variance")
col = 0
row = 0
@ -70,20 +71,26 @@ class GuiPlayerStats (threading.Thread):
col +=1
for row in range(rows-1):
for col in range(cols):
if(row%2 == 0):
bgcolor = "white"
else:
bgcolor = "lightgrey"
for col in range(cols):
eb = gtk.EventBox()
eb.modify_bg(gtk.STATE_NORMAL, gtk.gdk.color_parse(bgcolor))
l = gtk.Label(result[row-1][col])
if result[row][col]:
l = gtk.Label(result[row][col])
else:
l = gtk.Label(' ')
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()
eb.show()
def fillPlayerFrame(self, vbox):
for site in self.conf.supported_sites.keys():
hbox = gtk.HBox(False, 0)
@ -123,7 +130,6 @@ class GuiPlayerStats (threading.Thread):
def __set_hero_name(self, w, site):
self.heroes[site] = w.get_text()
print "DEBUG: settings heroes[%s]: %s"%(site, self.heroes[site])
def __init__(self, db, config, querylist, debug=True):
self.debug=debug

View File

@ -108,9 +108,9 @@ class fpdb_db:
self.cursor.execute(self.sql.query['createHandsPlayersTable'])
self.cursor.execute(self.sql.query['createHandsActionsTable'])
self.cursor.execute(self.sql.query['createHudCacheTable'])
self.cursor.execute(self.sql.query['addTourneyIndex'])
self.cursor.execute(self.sql.query['addHandsIndex'])
self.cursor.execute(self.sql.query['addPlayersIndex'])
#self.cursor.execute(self.sql.query['addTourneyIndex'])
#self.cursor.execute(self.sql.query['addHandsIndex'])
#self.cursor.execute(self.sql.query['addPlayersIndex'])
self.fillDefaultData()
self.db.commit()
#end def disconnect
@ -185,6 +185,7 @@ class fpdb_db:
self.drop_tables()
self.create_tables()
fpdb_simple.createAllIndexes(self)
self.db.commit()
print "Finished recreating tables"
#end def recreate_tables

View File

@ -36,6 +36,7 @@ import math
import os
import datetime
import re
import fpdb_db
import fpdb_simple
import fpdb_parse_logic
from time import time
@ -47,7 +48,7 @@ class Importer:
self.settings=settings
self.caller=caller
self.config = config
self.db = None
self.fdb = None
self.cursor = None
self.filelist = {}
self.dirlist = {}
@ -64,35 +65,12 @@ class Importer:
if not self.settings.has_key('handCount'):
#TODO: Is this value in the xml file?
self.settings['handCount'] = 0
self.dbConnect()
# XXX: Why is this here, when fpdb_db.connect() already does the
# same?
def dbConnect(self):
#connect to DB
if self.settings['db-backend'] == 2:
if not mysqlLibFound:
raise fpdb_simple.FpdbError("interface library MySQLdb not found but MySQL selected as backend - please install the library or change the config file")
self.db = MySQLdb.connect(self.settings['db-host'], self.settings['db-user'],
self.settings['db-password'], self.settings['db-databaseName'])
elif self.settings['db-backend'] == 3:
if not pgsqlLibFound:
raise fpdb_simple.FpdbError("interface library psycopg2 not found but PostgreSQL selected as backend - please install the library or change the config file")
print self.settings
if self.settings.has_key('db-host') and \
self.settings.has_key('db-user'):
self.db = psycopg2.connect(host = self.settings['db-host'],
user = self.settings['db-user'],
password = self.settings['db-password'],
database = self.settings['db-databaseName'])
else:
dbname = self.settings['db-databaseName']
self.db = psycopg2.connect(database = dbname)
elif self.settings['db-backend'] == 4:
pass
else:
pass
self.cursor = self.db.cursor()
self.fdb = fpdb_db.fpdb_db() # sets self.fdb.db self.fdb.cursor and self.fdb.sql
self.fdb.connect(self.settings['db-backend'],
self.settings['db-host'],
self.settings['db-databaseName'],
self.settings['db-user'],
self.settings['db-password'])
#Set functions
def setCallHud(self, value):
@ -138,8 +116,11 @@ class Importer:
#Run full import on filelist
def runImport(self):
fpdb_simple.prepareBulkImport(self.fdb)
for file in self.filelist:
self.import_file_dict(file, self.filelist[file][0], self.filelist[file][1])
fpdb_simple.afterBulkImport(self.fdb)
fpdb_simple.analyzeDB(self.fdb)
#Run import on updated files, then store latest update time.
def runUpdated(self):
@ -247,12 +228,11 @@ class Importer:
self.hand=hand
try:
handsId=fpdb_parse_logic.mainParser(self.settings['db-backend'], self.db
,self.cursor, site, category, hand)
self.db.commit()
handsId=fpdb_parse_logic.mainParser(self.settings['db-backend'], self.fdb.db
,self.fdb.cursor, site, category, hand)
self.fdb.db.commit()
stored+=1
self.db.commit()
if self.callHud:
#print "call to HUD here. handsId:",handsId
#pipe the Hands.id out to the HUD
@ -264,17 +244,17 @@ class Importer:
self.printEmailErrorMessage(errors, file, hand)
if (self.settings['failOnError']):
self.db.commit() #dont remove this, in case hand processing was cancelled.
self.fdb.db.commit() #dont remove this, in case hand processing was cancelled.
raise
except (fpdb_simple.FpdbError), fe:
errors+=1
self.printEmailErrorMessage(errors, file, hand)
#fe.printStackTrace() #todo: get stacktrace
self.db.rollback()
self.fdb.db.rollback()
if (self.settings['failOnError']):
self.db.commit() #dont remove this, in case hand processing was cancelled.
self.fdb.db.commit() #dont remove this, in case hand processing was cancelled.
raise
if (self.settings['minPrint']!=0):
if ((stored+duplicates+partial+errors)%self.settings['minPrint']==0):
@ -299,7 +279,7 @@ class Importer:
print "failed to read a single hand from file:", inputFile
handsId=0
#todo: this will cause return of an unstored hand number if the last hand was error or partial
self.db.commit()
self.fdb.db.commit()
self.handsId=handsId
return handsId
#end def import_file_dict

View File

@ -135,11 +135,11 @@ def mainParser(backend, db, cursor, site, category, hand):
if base=="hold":
hudImportData=fpdb_simple.generateHudCacheData(playerIDs, base, category, actionTypes
, allIns, actionTypeByNo, winnings, totalWinnings, positions
, actionTypes, actionAmounts)
, actionTypes, actionAmounts, None)
else:
hudImportData=fpdb_simple.generateHudCacheData(playerIDs, base, category, actionTypes
, allIns, actionTypeByNo, winnings, totalWinnings, None
, actionTypes, actionAmounts)
, actionTypes, actionAmounts, antes)
if isTourney:
ranks=[]

View File

@ -22,6 +22,11 @@ from time import time
import fpdb_simple
saveActions=True # set this to False to avoid storing action data
# Pros: speeds up imports
# Cons: no action data is saved, so you need to keep the hand histories
# variance not available on stats page
#stores a stud/razz hand into the database
def ring_stud(backend, db, cursor, base, category, site_hand_no, gametype_id, hand_start_time
,names, player_ids, start_cashes, antes, card_values, card_suits, winnings, rakes
@ -39,6 +44,7 @@ def ring_stud(backend, db, cursor, base, category, site_hand_no, gametype_id, ha
fpdb_simple.storeHudCache(cursor, base, category, gametype_id, player_ids, hudImportData)
if saveActions:
fpdb_simple.storeActions(cursor, hands_players_ids, action_types
,allIns, action_amounts, actionNos)
return hands_id
@ -66,10 +72,10 @@ def ring_holdem_omaha(backend, db, cursor, base, category, site_hand_no, gametyp
t5 = time()
fpdb_simple.store_board_cards(cursor, hands_id, board_values, board_suits)
t6 = time()
if saveActions:
fpdb_simple.storeActions(cursor, hands_players_ids, action_types, allIns, action_amounts, actionNos)
t7 = time()
print "cards=%4.3f board=%4.3f hands=%4.3f plyrs=%4.3f hudcache=%4.3f board=%4.3f actions=%4.3f" \
% (t1-t0, t2-t1, t3-t2, t4-t3, t5-t4, t6-t5, t7-t6)
#print "fills=(%4.3f) saves=(%4.3f,%4.3f,%4.3f,%4.3f)" % (t2-t0, t3-t2, t4-t3, t5-t4, t6-t5)
return hands_id
#end def ring_holdem_omaha
@ -98,6 +104,7 @@ def tourney_holdem_omaha(backend, db, cursor, base, category, siteTourneyNo, buy
fpdb_simple.store_board_cards(cursor, hands_id, board_values, board_suits)
if saveActions:
fpdb_simple.storeActions(cursor, hands_players_ids, action_types, allIns, action_amounts, actionNos)
return hands_id
#end def tourney_holdem_omaha
@ -122,6 +129,7 @@ def tourney_stud(backend, db, cursor, base, category, siteTourneyNo, buyin, fee,
fpdb_simple.storeHudCache(cursor, base, category, gametypeId, playerIds, hudImportData)
if saveActions:
fpdb_simple.storeActions(cursor, hands_players_ids, actionTypes, allIns, actionAmounts, actionNos)
return hands_id
#end def tourney_stud

View File

@ -27,6 +27,307 @@ MYSQL_INNODB=2
PGSQL=3
SQLITE=4
# Data Structures for index and foreign key creation
# drop_code is an int with possible values: 0 - don't drop for bulk import
# 1 - drop during bulk import
# db differences:
# - note that mysql automatically creates indexes on constrained columns when
# foreign keys are created, while postgres does not. Hence the much longer list
# of indexes is required for postgres.
# all primary keys are left on all the time
#
# table column drop_code
indexes = [
[ ] # no db with index 0
, [ ] # no db with index 1
, [ # indexes for mysql (list index 2)
{'tab':'Players', 'col':'name', 'drop':0}
, {'tab':'Hands', 'col':'siteHandNo', 'drop':0}
, {'tab':'Tourneys', 'col':'siteTourneyNo', 'drop':0}
]
, [ # indexes for postgres (list index 3)
{'tab':'Boardcards', 'col':'handId', 'drop':0}
, {'tab':'Gametypes', 'col':'siteId', 'drop':0}
, {'tab':'Hands', 'col':'gametypeId', 'drop':1}
, {'tab':'Hands', 'col':'siteHandNo', 'drop':0}
, {'tab':'HandsActions', 'col':'handplayerId', 'drop':0}
, {'tab':'HandsPlayers', 'col':'handId', 'drop':1}
, {'tab':'HandsPlayers', 'col':'playerId', 'drop':1}
, {'tab':'HandsPlayers', 'col':'tourneysPlayersId', 'drop':0}
, {'tab':'HudCache', 'col':'gametypeId', 'drop':1}
, {'tab':'HudCache', 'col':'playerId', 'drop':0}
, {'tab':'HudCache', 'col':'tourneyTypeId', 'drop':0}
, {'tab':'Players', 'col':'siteId', 'drop':1}
, {'tab':'Players', 'col':'name', 'drop':0}
, {'tab':'Tourneys', 'col':'tourneyTypeId', 'drop':1}
, {'tab':'Tourneys', 'col':'siteTourneyNo', 'drop':0}
, {'tab':'TourneysPlayers', 'col':'playerId', 'drop':0}
, {'tab':'TourneysPlayers', 'col':'tourneyId', 'drop':0}
, {'tab':'TourneyTypes', 'col':'siteId', 'drop':0}
]
]
foreignKeys = [
[ ] # no db with index 0
, [ ] # no db with index 1
, [ # foreign keys for mysql
{'fktab':'Hands', 'fkcol':'gametypeId', 'rtab':'Gametypes', 'rcol':'id', 'drop':1}
, {'fktab':'HandsPlayers', 'fkcol':'handId', 'rtab':'Hands', 'rcol':'id', 'drop':1}
, {'fktab':'HandsPlayers', 'fkcol':'playerId', 'rtab':'Players', 'rcol':'id', 'drop':1}
, {'fktab':'HandsActions', 'fkcol':'handPlayerId', 'rtab':'HandsPlayers', 'rcol':'id', 'drop':1}
, {'fktab':'HudCache', 'fkcol':'gametypeId', 'rtab':'Gametypes', 'rcol':'id', 'drop':1}
, {'fktab':'HudCache', 'fkcol':'playerId', 'rtab':'Players', 'rcol':'id', 'drop':0}
, {'fktab':'HudCache', 'fkcol':'tourneyTypeId', 'rtab':'TourneyTypes', 'rcol':'id', 'drop':1}
]
, [ # foreign keys for postgres
{'fktab':'Hands', 'fkcol':'gametypeId', 'rtab':'Gametypes', 'rcol':'id', 'drop':1}
, {'fktab':'HandsPlayers', 'fkcol':'handId', 'rtab':'Hands', 'rcol':'id', 'drop':1}
, {'fktab':'HandsPlayers', 'fkcol':'playerId', 'rtab':'Players', 'rcol':'id', 'drop':1}
, {'fktab':'HandsActions', 'fkcol':'handPlayerId', 'rtab':'HandsPlayers', 'rcol':'id', 'drop':1}
, {'fktab':'HudCache', 'fkcol':'gametypeId', 'rtab':'Gametypes', 'rcol':'id', 'drop':1}
, {'fktab':'HudCache', 'fkcol':'playerId', 'rtab':'Players', 'rcol':'id', 'drop':0}
, {'fktab':'HudCache', 'fkcol':'tourneyTypeId', 'rtab':'TourneyTypes', 'rcol':'id', 'drop':1}
]
]
# MySQL Notes:
# "FOREIGN KEY (handId) REFERENCES Hands(id)" - requires index on Hands.id
# - creates index handId on <thistable>.handId
# alter table t drop foreign key fk
# alter table t add foreign key (fkcol) references tab(rcol)
# alter table t add constraint c foreign key (fkcol) references tab(rcol)
# (fkcol is used for foreigh key name)
# mysql to list indexes:
# SELECT table_name, index_name, non_unique, column_name
# FROM INFORMATION_SCHEMA.STATISTICS
# WHERE table_name = 'tbl_name'
# AND table_schema = 'db_name'
# ORDER BY table_name, index_name, seq_in_index
#
# ALTER TABLE Tourneys ADD INDEX siteTourneyNo(siteTourneyNo)
# ALTER TABLE tab DROP INDEX idx
# mysql to list fks:
# SELECT constraint_name, table_name, column_name, referenced_table_name, referenced_column_name
# FROM information_schema.KEY_COLUMN_USAGE
# WHERE REFERENCED_TABLE_SCHEMA = (your schema name here)
# AND REFERENCED_TABLE_NAME is not null
# ORDER BY TABLE_NAME, COLUMN_NAME;
# this may indicate missing object
# _mysql_exceptions.OperationalError: (1025, "Error on rename of '.\\fpdb\\hands' to '.\\fpdb\\#sql2-7f0-1b' (errno: 152)")
# PG notes:
# To add a foreign key constraint to a table:
# ALTER TABLE tab ADD CONSTRAINT c FOREIGN KEY (col) REFERENCES t2(col2) MATCH FULL;
# ALTER TABLE tab DROP CONSTRAINT zipchk
#
# Note: index names must be unique across a schema
# CREATE INDEX idx ON tab(col)
# DROP INDEX idx
def prepareBulkImport(fdb):
"""Drop some indexes/foreign keys to prepare for bulk import.
Currently keeping the standalone indexes as needed to import quickly"""
# fdb is a fpdb_db object including backend, db, cursor, sql variables
if fdb.backend == PGSQL:
fdb.db.set_isolation_level(0) # allow table/index operations to work
for fk in foreignKeys[fdb.backend]:
if fk['drop'] == 1:
if fdb.backend == MYSQL_INNODB:
fdb.cursor.execute("SELECT constraint_name " +
"FROM information_schema.KEY_COLUMN_USAGE " +
#"WHERE REFERENCED_TABLE_SCHEMA = 'fpdb'
"WHERE 1=1 " +
"AND table_name = %s AND column_name = %s " +
"AND referenced_table_name = %s " +
"AND referenced_column_name = %s ",
(fk['fktab'], fk['fkcol'], fk['rtab'], fk['rcol']) )
cons = fdb.cursor.fetchone()
print "preparebulk: cons=", cons
if cons:
print "dropping mysql fk", cons[0], fk['fktab'], fk['fkcol']
try:
fdb.cursor.execute("alter table " + fk['fktab'] + " drop foreign key " + cons[0])
except:
pass
elif fdb.backend == PGSQL:
print "dropping pg fk", fk['fktab'], fk['fkcol']
try:
fdb.cursor.execute("alter table " + fk['fktab'] + " drop constraint "
+ fk['fktab'] + '_' + fk['fkcol'] + '_fkey')
except:
pass
else:
print "Only MySQL and Postgres supported so far"
return -1
for idx in indexes[fdb.backend]:
if idx['drop'] == 1:
if fdb.backend == MYSQL_INNODB:
print "dropping mysql index ", idx['tab'], idx['col']
try:
fdb.cursor.execute( "alter table %s drop index %s", (idx['tab'],idx['col']) )
except:
pass
elif fdb.backend == PGSQL:
print "dropping pg index ", idx['tab'], idx['col']
# mod to use tab_col for index name?
try:
fdb.cursor.execute( "drop index %s_%s_idx" % (idx['tab'],idx['col']) )
except:
pass
else:
print "Only MySQL and Postgres supported so far"
return -1
if fdb.backend == PGSQL:
fdb.db.set_isolation_level(1) # go back to normal isolation level
fdb.db.commit() # seems to clear up errors if there were any in postgres
#end def prepareBulkImport
def afterBulkImport(fdb):
"""Re-create any dropped indexes/foreign keys after bulk import"""
# fdb is a fpdb_db object including backend, db, cursor, sql variables
if fdb.backend == PGSQL:
fdb.db.set_isolation_level(0) # allow table/index operations to work
for fk in foreignKeys[fdb.backend]:
if fk['drop'] == 1:
if fdb.backend == MYSQL_INNODB:
fdb.cursor.execute("SELECT constraint_name " +
"FROM information_schema.KEY_COLUMN_USAGE " +
#"WHERE REFERENCED_TABLE_SCHEMA = 'fpdb'
"WHERE 1=1 " +
"AND table_name = %s AND column_name = %s " +
"AND referenced_table_name = %s " +
"AND referenced_column_name = %s ",
(fk['fktab'], fk['fkcol'], fk['rtab'], fk['rcol']) )
cons = fdb.cursor.fetchone()
print "afterbulk: cons=", cons
if cons:
pass
else:
print "creating fk ", fk['fktab'], fk['fkcol'], "->", fk['rtab'], fk['rcol']
try:
fdb.cursor.execute("alter table " + fk['fktab'] + " add foreign key ("
+ fk['fkcol'] + ") references " + fk['rtab'] + "("
+ fk['rcol'] + ")")
except:
pass
elif fdb.backend == PGSQL:
print "creating fk ", fk['fktab'], fk['fkcol'], "->", fk['rtab'], fk['rcol']
try:
fdb.cursor.execute("alter table " + fk['fktab'] + " add constraint "
+ fk['fktab'] + '_' + fk['fkcol'] + '_fkey'
+ " foreign key (" + fk['fkcol']
+ ") references " + fk['rtab'] + "(" + fk['rcol'] + ")")
except:
pass
else:
print "Only MySQL and Postgres supported so far"
return -1
for idx in indexes[fdb.backend]:
if idx['drop'] == 1:
if fdb.backend == MYSQL_INNODB:
print "creating mysql index ", idx['tab'], idx['col']
try:
fdb.cursor.execute( "alter table %s add index %s(%s)"
, (idx['tab'],idx['col'],idx['col']) )
except:
pass
elif fdb.backend == PGSQL:
# mod to use tab_col for index name?
print "creating pg index ", idx['tab'], idx['col']
try:
print "create index %s_%s_idx on %s(%s)" % (idx['tab'], idx['col'], idx['tab'], idx['col'])
fdb.cursor.execute( "create index %s_%s_idx on %s(%s)"
% (idx['tab'], idx['col'], idx['tab'], idx['col']) )
except:
print " ERROR! :-("
pass
else:
print "Only MySQL and Postgres supported so far"
return -1
if fdb.backend == PGSQL:
fdb.db.set_isolation_level(1) # go back to normal isolation level
fdb.db.commit() # seems to clear up errors if there were any in postgres
#end def afterBulkImport
def createAllIndexes(fdb):
"""Create new indexes"""
if fdb.backend == PGSQL:
fdb.db.set_isolation_level(0) # allow table/index operations to work
for idx in indexes[fdb.backend]:
if fdb.backend == MYSQL_INNODB:
print "creating mysql index ", idx['tab'], idx['col']
try:
fdb.cursor.execute( "alter table %s add index %s(%s)"
, (idx['tab'],idx['col'],idx['col']) )
except:
pass
elif fdb.backend == PGSQL:
# mod to use tab_col for index name?
print "creating pg index ", idx['tab'], idx['col']
try:
print "create index %s_%s_idx on %s(%s)" % (idx['tab'], idx['col'], idx['tab'], idx['col'])
fdb.cursor.execute( "create index %s_%s_idx on %s(%s)"
% (idx['tab'], idx['col'], idx['tab'], idx['col']) )
except:
print " ERROR! :-("
pass
else:
print "Only MySQL and Postgres supported so far"
return -1
if fdb.backend == PGSQL:
fdb.db.set_isolation_level(1) # go back to normal isolation level
#end def createAllIndexes
def dropAllIndexes(fdb):
"""Drop all standalone indexes (i.e. not including primary keys or foreign keys)
using list of indexes in indexes data structure"""
# maybe upgrade to use data dictionary?? (but take care to exclude PK and FK)
if fdb.backend == PGSQL:
fdb.db.set_isolation_level(0) # allow table/index operations to work
for idx in indexes[fdb.backend]:
if fdb.backend == MYSQL_INNODB:
print "dropping mysql index ", idx['tab'], idx['col']
try:
fdb.cursor.execute( "alter table %s drop index %s"
, (idx['tab'],idx['col']) )
except:
pass
elif fdb.backend == PGSQL:
print "dropping pg index ", idx['tab'], idx['col']
# mod to use tab_col for index name?
try:
fdb.cursor.execute( "drop index %s_%s_idx"
% (idx['tab'],idx['col']) )
except:
pass
else:
print "Only MySQL and Postgres supported so far"
return -1
if fdb.backend == PGSQL:
fdb.db.set_isolation_level(1) # go back to normal isolation level
#end def dropAllIndexes
def analyzeDB(fdb):
"""Do whatever the DB can offer to update index/table statistics"""
if fdb.backend == PGSQL:
fdb.db.set_isolation_level(0) # allow vacuum to work
try:
fdb.cursor.execute("vacuum analyze")
except:
print "Error during vacuum"
fdb.db.set_isolation_level(1) # go back to normal isolation level
#end def analyzeDB
class DuplicateError(Exception):
def __init__(self, value):
@ -1426,7 +1727,7 @@ VALUES (%s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s, %s,
#end def store_hands_players_stud_tourney
def generateHudCacheData(player_ids, base, category, action_types, allIns, actionTypeByNo
,winnings, totalWinnings, positions, actionTypes, actionAmounts):
,winnings, totalWinnings, positions, actionTypes, actionAmounts, antes):
"""calculates data for the HUD during import. IMPORTANT: if you change this method make
sure to also change the following storage method and table_viewer.prepare_data if necessary
"""
@ -1953,7 +2254,9 @@ sure to also change the following storage method and table_viewer.prepare_data i
#print "b4 totprof calc, len(playerIds)=", len(player_ids)
for pl in range (len(player_ids)):
#print "pl=", pl
myTotalProfit=winnings[pl] # still need to deduct costs
myTotalProfit=winnings[pl] # still need to deduct other costs
if antes:
myTotalProfit=winnings[pl] - antes[pl]
for i in range (len(actionTypes)): #iterate through streets
#for j in range (len(actionTypes[i])): #iterate through names (using pl loop above)
for k in range (len(actionTypes[i][pl])): #iterate through individual actions of that player on that street