From e2dde5c3e3285cca0d815b77352081148ad264b9 Mon Sep 17 00:00:00 2001 From: sqlcoder Date: Sat, 1 Aug 2009 23:15:04 +0100 Subject: [PATCH] fix aggregate query and stop hud queries being executed whenever anything created a db connection --- pyfpdb/Database.py | 89 +++++++++++++++++++------------- pyfpdb/HUD_main.py | 7 ++- pyfpdb/SQL.py | 126 +++++++++++++++++++++++++++++---------------- 3 files changed, 139 insertions(+), 83 deletions(-) diff --git a/pyfpdb/Database.py b/pyfpdb/Database.py index 82a71331..f9ebea39 100755 --- a/pyfpdb/Database.py +++ b/pyfpdb/Database.py @@ -190,7 +190,7 @@ class Database: # (hands every 2 mins for 1 hour = one session, if followed # by a 40 minute gap and then more hands on same table that is # a new session) - self.hud_style = 'T' # A=All-time + self.hud_style = 'A' # A=All-time # S=Session # T=timed (last n days) # Future values may also include: @@ -198,41 +198,17 @@ class Database: self.hud_hands = 2000 # Max number of hands from each player to use for hud stats self.hud_days = 30 # Max number of days from each player to use for hud stats - self.hud_hero_style = 'T' # Duplicate set of vars just for hero - self.hud_hero_hands = 2000 - self.hud_hero_days = 30 + #self.hud_hero_style = 'T' # Duplicate set of vars just for hero - not used yet. + #self.hud_hero_hands = 2000 # Idea is that you might want all-time stats for others + #self.hud_hero_days = 30 # but last T days or last H hands for yourself + + # vars for hand ids or dates fetched according to above config: + self.hand_1day_ago = 0 # max hand id more than 24 hrs earlier than now + self.date_ndays_ago = 'd000000' # date N days ago ('d' + YYMMDD) + self.date_nhands_ago = {} # dates N hands ago per player - not used yet self.cursor = self.fdb.cursor - if self.fdb.wrongDbVersion == False: - # self.hand_1day_ago used to fetch stats for current session (i.e. if hud_style = 'S') - self.hand_1day_ago = 0 - self.cursor.execute(self.sql.query['get_hand_1day_ago']) - row = self.cursor.fetchone() - if row and row[0]: - self.hand_1day_ago = row[0] - #print "hand 1day ago =", self.hand_1day_ago - - # self.date_ndays_ago used if hud_style = 'T' - d = timedelta(days=self.hud_days) - now = datetime.utcnow() - d - self.date_ndays_ago = "d%02d%02d%02d" % (now.year-2000, now.month, now.day) - - # self.hand_nhands_ago is used for fetching stats for last n hands (hud_style = 'H') - # This option not used yet - self.hand_nhands_ago = 0 - # should use aggregated version of query if appropriate - self.cursor.execute(self.sql.query['get_hand_nhands_ago'], (self.hud_hands,self.hud_hands)) - row = self.cursor.fetchone() - if row and row[0]: - self.hand_nhands_ago = row[0] - print "hand n hands ago =", self.hand_nhands_ago - - #self.cursor.execute(self.sql.query['get_table_name'], (hand_id, )) - #row = self.cursor.fetchone() - else: - print "Bailing on DB query, not sure it exists yet" - self.saveActions = False if self.import_options['saveActions'] == False else True self.connection.rollback() # make sure any locks taken so far are released @@ -365,6 +341,45 @@ class Database: winners[row[0]] = row[1] return winners + def init_hud_stat_vars(self): + """Initialise variables used by Hud to fetch stats.""" + + try: + # self.hand_1day_ago used to fetch stats for current session (i.e. if hud_style = 'S') + self.hand_1day_ago = 1 + c = self.get_cursor() + c.execute(self.sql.query['get_hand_1day_ago']) + row = c.fetchone() + if row and row[0]: + self.hand_1day_ago = row[0] + #print "hand 1day ago =", self.hand_1day_ago + + # self.date_ndays_ago used if hud_style = 'T' + d = timedelta(days=self.hud_days) + now = datetime.utcnow() - d + self.date_ndays_ago = "d%02d%02d%02d" % (now.year-2000, now.month, now.day) + except: + err = traceback.extract_tb(sys.exc_info()[2])[-1] + print "***Error: "+err[2]+"("+str(err[1])+"): "+str(sys.exc_info()[1]) + + def init_player_hud_stat_vars(self, playerid): + # not sure if this is workable, to be continued ... + try: + # self.date_nhands_ago is used for fetching stats for last n hands (hud_style = 'H') + # This option not used yet - needs to be called for each player :-( + self.date_nhands_ago[str(playerid)] = 'd000000' + + # should use aggregated version of query if appropriate + c.execute(self.sql.query['get_date_nhands_ago'], (self.hud_hands, playerid)) + row = c.fetchone() + if row and row[0]: + self.date_nhands_ago[str(playerid)] = row[0] + c.close() + print "date n hands ago = " + self.date_nhands_ago[str(playerid)] + "(playerid "+str(playerid)+")" + except: + err = traceback.extract_tb(sys.exc_info()[2])[-1] + print "***Error: "+err[2]+"("+str(err[1])+"): "+str(sys.exc_info()[1]) + def get_stats_from_hand(self, hand, aggregate = False): if self.hud_style == 'S': return( self.get_stats_from_hand_session(hand) ) @@ -376,11 +391,13 @@ class Database: if self.hud_style == 'T': stylekey = self.date_ndays_ago + #elif self.hud_style == 'H': + # stylekey = self.date_nhands_ago needs array by player here ... else: # assume A (all-time) stylekey = '0000000' # all stylekey values should be higher than this - subs = (hand, hand, stylekey) - #print "get stats: hud style =", self.hud_style, "subs =", subs + subs = (hand, stylekey) + #print "get stats: hud style =", self.hud_style, "query =", query, "subs =", subs c = self.connection.cursor() # now get the stats @@ -409,7 +426,7 @@ class Database: return None subs = (self.hand_1day_ago, hand) - c = self.connection.cursor() + c = self.get_cursor() # now get the stats #print "sess_stats: subs =", subs, "subs[0] =", subs[0] diff --git a/pyfpdb/HUD_main.py b/pyfpdb/HUD_main.py index 7378d6f7..b65a73b1 100755 --- a/pyfpdb/HUD_main.py +++ b/pyfpdb/HUD_main.py @@ -31,6 +31,7 @@ Main for FreePokerTools HUD. import sys import os import Options +import traceback (options, sys.argv) = Options.fpdb_options() @@ -55,7 +56,7 @@ import Database import Tables import Hud -aggregate_stats = {"ring": False, "tour": False} # config file! +aggregate_stats = {"ring": True, "tour": False} # config file! class HUD_main(object): """A main() object to own both the read_stdin thread and the gui.""" @@ -144,6 +145,7 @@ class HUD_main(object): # need their own access to the database, but should open their own # if it is required. self.db_connection = Database.Database(self.config, self.db_name, 'temp') + self.db_connection.init_hud_stat_vars() tourny_finder = re.compile('(\d+) (\d+)') while 1: # wait for a new hand number on stdin @@ -162,7 +164,8 @@ class HUD_main(object): if comm_cards != {}: # stud! cards['common'] = comm_cards['common'] except Exception, err: - print "db error: skipping ", new_hand_id, err + err = traceback.extract_tb(sys.exc_info()[2])[-1] + print "db error: skipping "+str(new_hand_id)+" "+err[2]+"("+str(err[1])+"): "+str(sys.exc_info()[1]) if new_hand_id: # new_hand_id is none if we had an error prior to the store sys.stderr.write("Database error %s in hand %d. Skipping.\n" % (err, int(new_hand_id))) continue diff --git a/pyfpdb/SQL.py b/pyfpdb/SQL.py index 39315ee1..87242a8b 100644 --- a/pyfpdb/SQL.py +++ b/pyfpdb/SQL.py @@ -167,9 +167,9 @@ class Sql: ################################ if db_server == 'mysql': self.query['list_tables'] = """SHOW TABLES""" - elif db_server == 'postgresql': # what is the correct value here? + elif db_server == 'postgresql': self.query['list_tables'] = """SELECT table_name FROM information_schema.tables WHERE table_schema = 'public'""" - elif db_server == 'sqlite': # what is the correct value here? + elif db_server == 'sqlite': self.query['list_tables'] = """SELECT name FROM sqlite_master WHERE type='table' ORDER BY name;""" @@ -188,10 +188,10 @@ class Sql: self.query['createSettingsTable'] = """CREATE TABLE Settings ( version SMALLINT NOT NULL) ENGINE=INNODB""" - elif db_server == 'postgresql': # what is the correct value here? + elif db_server == 'postgresql': self.query['createSettingsTable'] = """CREATE TABLE Settings (version SMALLINT)""" - elif db_server == 'sqlite': # what is the correct value here? + elif db_server == 'sqlite': self.query['createSettingsTable'] = """CREATE TABLE Settings (version INTEGER) """ @@ -206,12 +206,12 @@ class Sql: name varchar(32) NOT NULL, currency char(3) NOT NULL) ENGINE=INNODB""" - elif db_server == 'postgresql': # what is the correct value here? + elif db_server == 'postgresql': self.query['createSitesTable'] = """CREATE TABLE Sites ( id SERIAL, PRIMARY KEY (id), name varchar(32), currency char(3))""" - elif db_server == 'sqlite': # what is the correct value here? + elif db_server == 'sqlite': self.query['createSitesTable'] = """CREATE TABLE Sites ( id INTEGER PRIMARY KEY, name TEXT NOT NULL, @@ -236,7 +236,7 @@ class Sql: smallBet int NOT NULL, bigBet int NOT NULL) ENGINE=INNODB""" - elif db_server == 'postgresql': # what is the correct value here? + elif db_server == 'postgresql': self.query['createGametypesTable'] = """CREATE TABLE Gametypes ( id SERIAL, PRIMARY KEY (id), siteId INTEGER, FOREIGN KEY (siteId) REFERENCES Sites(id), @@ -249,7 +249,7 @@ class Sql: bigBlind int, smallBet int, bigBet int)""" - elif db_server == 'sqlite': # what is the correct value here? + elif db_server == 'sqlite': self.query['createGametypesTable'] = """CREATE TABLE GameTypes ( id INTEGER PRIMARY KEY, siteId INTEGER, @@ -277,14 +277,14 @@ class Sql: comment text, commentTs DATETIME) ENGINE=INNODB""" - elif db_server == 'postgresql': # what is the correct value here? + elif db_server == 'postgresql': self.query['createPlayersTable'] = """CREATE TABLE Players ( id SERIAL, PRIMARY KEY (id), name VARCHAR(32), siteId INTEGER, FOREIGN KEY (siteId) REFERENCES Sites(id), comment text, commentTs timestamp without time zone)""" - elif db_server == 'sqlite': # what is the correct value here? + elif db_server == 'sqlite': self.query['createPlayersTable'] = """CREATE TABLE Players ( id INTEGER PRIMARY KEY, name TEXT, @@ -308,7 +308,7 @@ class Sql: ratingTime DATETIME NOT NULL, handCount int NOT NULL) ENGINE=INNODB""" - elif db_server == 'postgresql': # what is the correct value here? + elif db_server == 'postgresql': self.query['createAutoratesTable'] = """CREATE TABLE Autorates ( id BIGSERIAL, PRIMARY KEY (id), playerId INT, FOREIGN KEY (playerId) REFERENCES Players(id), @@ -317,7 +317,7 @@ class Sql: shortDesc char(8), ratingTime timestamp without time zone, handCount int)""" - elif db_server == 'sqlite': # what is the correct value here? + elif db_server == 'sqlite': self.query['createAutoratesTable'] = """ """ @@ -360,7 +360,7 @@ class Sql: comment TEXT, commentTs DATETIME) ENGINE=INNODB""" - elif db_server == 'postgresql': # what is the correct value here? + elif db_server == 'postgresql': self.query['createHandsTable'] = """CREATE TABLE Hands ( id BIGSERIAL, PRIMARY KEY (id), tableName VARCHAR(20) NOT NULL, @@ -394,7 +394,7 @@ class Sql: showdownPot INT, /* pot size at sd/street7 */ comment TEXT, commentTs timestamp without time zone)""" - elif db_server == 'sqlite': # what is the correct value here? + elif db_server == 'sqlite': self.query['createHandsTable'] = """CREATE TABLE Hands ( id INTEGER PRIMARY KEY, tableName TEXT(20), @@ -422,7 +422,7 @@ class Sql: knockout INT NOT NULL, rebuyOrAddon BOOLEAN NOT NULL) ENGINE=INNODB""" - elif db_server == 'postgresql': # what is the correct value here? + elif db_server == 'postgresql': self.query['createTourneyTypesTable'] = """CREATE TABLE TourneyTypes ( id SERIAL, PRIMARY KEY (id), siteId INT, FOREIGN KEY (siteId) REFERENCES Sites(id), @@ -430,7 +430,7 @@ class Sql: fee INT, knockout INT, rebuyOrAddon BOOLEAN)""" - elif db_server == 'sqlite': # what is the correct value here? + elif db_server == 'sqlite': self.query['createTourneyTypesTable'] = """ """ @@ -449,7 +449,7 @@ class Sql: comment TEXT, commentTs DATETIME) ENGINE=INNODB""" - elif db_server == 'postgresql': # what is the correct value here? + elif db_server == 'postgresql': self.query['createTourneysTable'] = """CREATE TABLE Tourneys ( id SERIAL, PRIMARY KEY (id), tourneyTypeId INT, FOREIGN KEY (tourneyTypeId) REFERENCES TourneyTypes(id), @@ -459,7 +459,7 @@ class Sql: startTime timestamp without time zone, comment TEXT, commentTs timestamp without time zone)""" - elif db_server == 'sqlite': # what is the correct value here? + elif db_server == 'sqlite': self.query['createTourneysTable'] = """CREATE TABLE TourneyTypes ( id INTEGER PRIMARY KEY, siteId INTEGER, @@ -591,7 +591,7 @@ class Sql: FOREIGN KEY (tourneysPlayersId) REFERENCES TourneysPlayers(id)) ENGINE=INNODB""" - elif db_server == 'postgresql': # what is the correct value here? + elif db_server == 'postgresql': self.query['createHandsPlayersTable'] = """CREATE TABLE HandsPlayers ( id BIGSERIAL, PRIMARY KEY (id), handId BIGINT NOT NULL, FOREIGN KEY (handId) REFERENCES Hands(id), @@ -708,7 +708,7 @@ class Sql: actionString VARCHAR(15), FOREIGN KEY (tourneysPlayersId) REFERENCES TourneysPlayers(id))""" - elif db_server == 'sqlite': # what is the correct value here? + elif db_server == 'sqlite': self.query['createHandsPlayersTable'] = """ """ @@ -727,7 +727,7 @@ class Sql: comment TEXT, commentTs DATETIME) ENGINE=INNODB""" - elif db_server == 'postgresql': # what is the correct value here? + elif db_server == 'postgresql': self.query['createTourneysPlayersTable'] = """CREATE TABLE TourneysPlayers ( id BIGSERIAL, PRIMARY KEY (id), tourneyId INT, FOREIGN KEY (tourneyId) REFERENCES Tourneys(id), @@ -737,7 +737,7 @@ class Sql: winnings INT, comment TEXT, commentTs timestamp without time zone)""" - elif db_server == 'sqlite': # what is the correct value here? + elif db_server == 'sqlite': self.query['createTourneysPlayersTable'] = """ """ @@ -757,7 +757,7 @@ class Sql: comment TEXT, commentTs DATETIME) ENGINE=INNODB""" - elif db_server == 'postgresql': # what is the correct value here? + elif db_server == 'postgresql': self.query['createHandsActionsTable'] = """CREATE TABLE HandsActions ( id BIGSERIAL, PRIMARY KEY (id), handsPlayerId BIGINT, FOREIGN KEY (handsPlayerId) REFERENCES HandsPlayers(id), @@ -768,7 +768,7 @@ class Sql: amount INT, comment TEXT, commentTs timestamp without time zone)""" - elif db_server == 'sqlite': # what is the correct value here? + elif db_server == 'sqlite': self.query['createHandsActionsTable'] = """ """ @@ -877,7 +877,7 @@ class Sql: street4Raises INT) ENGINE=INNODB""" - elif db_server == 'postgresql': # what is the correct value here? + elif db_server == 'postgresql': self.query['createHudCacheTable'] = """CREATE TABLE HudCache ( id BIGSERIAL, PRIMARY KEY (id), gametypeId INT, FOREIGN KEY (gametypeId) REFERENCES Gametypes(id), @@ -976,28 +976,28 @@ class Sql: street3Raises INT, street4Raises INT) """ - elif db_server == 'sqlite': # what is the correct value here? + elif db_server == 'sqlite': self.query['createHudCacheTable'] = """ """ if db_server == 'mysql': self.query['addTourneyIndex'] = """ALTER TABLE Tourneys ADD INDEX siteTourneyNo(siteTourneyNo)""" - elif db_server == 'postgresql': # what is the correct value here? + elif db_server == 'postgresql': self.query['addTourneyIndex'] = """CREATE INDEX siteTourneyNo ON Tourneys (siteTourneyNo)""" - elif db_server == 'sqlite': # what is the correct value here? + elif db_server == 'sqlite': self.query['addHandsIndex'] = """ """ if db_server == 'mysql': self.query['addHandsIndex'] = """ALTER TABLE Hands ADD INDEX siteHandNo(siteHandNo)""" - elif db_server == 'postgresql': # what is the correct value here? + elif db_server == 'postgresql': self.query['addHandsIndex'] = """CREATE INDEX siteHandNo ON Hands (siteHandNo)""" - elif db_server == 'sqlite': # what is the correct value here? + elif db_server == 'sqlite': self.query['addHandsIndex'] = """ """ if db_server == 'mysql': self.query['addPlayersIndex'] = """ALTER TABLE Players ADD INDEX name(name)""" - elif db_server == 'postgresql': # what is the correct value here? + elif db_server == 'postgresql': self.query['addPlayersIndex'] = """CREATE INDEX name ON Players (name)""" - elif db_server == 'sqlite': # what is the correct value here? + elif db_server == 'sqlite': self.query['addPlayersIndex'] = """ """ @@ -1073,7 +1073,7 @@ class Sql: sum(hc.street4CheckCallRaiseChance) AS ccr_opp_4, sum(hc.street4CheckCallRaiseDone) AS ccr_4 FROM Hands h - INNER JOIN HandsPlayers hp ON (hp.handId = %s) + INNER JOIN HandsPlayers hp ON (hp.handId = h.id) INNER JOIN HudCache hc ON ( hc.PlayerId = hp.PlayerId+0 AND hc.gametypeId+0 = h.gametypeId+0) INNER JOIN Players p ON (p.id = hp.PlayerId+0) @@ -1155,17 +1155,19 @@ class Sql: sum(hc.street4CheckCallRaiseChance) AS ccr_opp_4, sum(hc.street4CheckCallRaiseDone) AS ccr_4 FROM Hands h - INNER JOIN HandsPlayers hp ON (hp.handId = %s) + INNER JOIN HandsPlayers hp ON (hp.handId = h.id) INNER JOIN HudCache hc ON (hc.playerId = hp.playerId) INNER JOIN Players p ON (p.id = hc.playerId) WHERE h.id = %s AND hc.styleKey > %s /* styleKey is currently 'd' (for date) followed by a yyyymmdd date key. Set it to 0000000 or similar to get all records */ - /* also check activeseats here? even if only 3 groups eg 2-3/4-6/7+ ?? + /* Note: s means the placeholder 'percent's but we can't include that + in comments. (db api thinks they are actual arguments) + Could also check activeseats here? even if only 3 groups eg 2-3/4-6/7+ ?? e.g. could use a multiplier: - AND h.seats > %s / 1.25 and hp.seats < %s * 1.25 - where %s is the number of active players at the current table (and + AND h.seats > s / 1.25 and hp.seats < s * 1.25 + where s is the number of active players at the current table (and 1.25 would be a config value so user could change it) */ AND hc.gametypeId+0 in @@ -1406,16 +1408,50 @@ class Sql: select coalesce(max(id),0) from Hands where handStart < date_sub(utc_timestamp(), interval '1' day)""" - else: # assume postgresql + elif db_server == 'postgresql': self.query['get_hand_1day_ago'] = """ select coalesce(max(id),0) from Hands where handStart < now() at time zone 'UTC' - interval '1 day'""" - #if db_server == 'mysql': - self.query['get_hand_nhands_ago'] = """ - select coalesce(greatest(max(id),%s)-%s,0) - from Hands""" + # not used yet ... + # gets a date, would need to use handsplayers (not hudcache) to get exact hand Id + if db_server == 'mysql': + self.query['get_date_nhands_ago'] = """ + select concat( 'd', date_format(max(h.handStart), '%Y%m%d') ) + from (select hp.playerId + ,coalesce(greatest(max(hp.handId)-%s,1),1) as maxminusx + from HandsPlayers hp + where hp.playerId = %s + group by hp.playerId) hp2 + inner join HandsPlayers hp3 on ( hp3.handId <= hp2.maxminusx + and hp3.playerId = hp2.playerId) + inner join Hands h on (h.id = hp3.handId) + """ + elif db_server == 'postgresql': + self.query['get_date_nhands_ago'] = """ + select 'd' || to_char(max(h3.handStart), 'YYMMDD') + from (select hp.playerId + ,coalesce(greatest(max(hp.handId)-%s,1),1) as maxminusx + from HandsPlayers hp + where hp.playerId = %s + group by hp.playerId) hp2 + inner join HandsPlayers hp3 on ( hp3.handId <= hp2.maxminusx + and hp3.playerId = hp2.playerId) + inner join Hands h on (h.id = hp3.handId) + """ + elif db_server == 'sqlite': # untested guess at query: + self.query['get_date_nhands_ago'] = """ + select 'd' || strftime(max(h3.handStart), 'YYMMDD') + from (select hp.playerId + ,coalesce(greatest(max(hp.handId)-%s,1),1) as maxminusx + from HandsPlayers hp + where hp.playerId = %s + group by hp.playerId) hp2 + inner join HandsPlayers hp3 on ( hp3.handId <= hp2.maxminusx + and hp3.playerId = hp2.playerId) + inner join Hands h on (h.id = hp3.handId) + """ # used in GuiPlayerStats: self.query['getPlayerId'] = """SELECT id from Players where name = %s""" @@ -1586,7 +1622,7 @@ class Sql: ,upper(gt.limitType) ,s.name """ - #elif db_server == 'sqlite': # what is the correct value here? + #elif db_server == 'sqlite': # self.query['playerDetailedStats'] = """ """ if db_server == 'mysql': @@ -1798,7 +1834,7 @@ class Sql: ) hprof2 on hprof2.gtId = stats.gtId order by stats.base, stats.limittype, stats.bigBlindDesc desc """ - #elif db_server == 'sqlite': # what is the correct value here? + #elif db_server == 'sqlite': # self.query['playerStats'] = """ """ if db_server == 'mysql': @@ -2073,7 +2109,7 @@ class Sql: order by stats.category, stats.limitType, stats.bigBlindDesc desc , cast(stats.PlPosition as smallint) """ - #elif db_server == 'sqlite': # what is the correct value here? + #elif db_server == 'sqlite': # self.query['playerStatsByPosition'] = """ """ self.query['getRingProfitAllHandsPlayerIdSite'] = """