Finished up code for creating and updating SessionsCache. Table includes fields for sessionStart, sessionEnd, ring hands, tournament hands, ring totalProfit, and ring bigBets won during each session. bigBets field is a python float stored as a REAL in the database (I am open to alternative suggestions). Also, storeSessions is currently set to False.
This commit is contained in:
		
							parent
							
								
									c2cda3bf87
								
							
						
					
					
						commit
						0c46965d98
					
				| 
						 | 
				
			
			@ -260,6 +260,8 @@ class Database:
 | 
			
		|||
        
 | 
			
		||||
        if 'day_start' in gen:
 | 
			
		||||
            self.day_start = float(gen['day_start'])
 | 
			
		||||
            
 | 
			
		||||
        self.sessionTimeout = float(self.import_options['sessionTimeout'])
 | 
			
		||||
 | 
			
		||||
        # where possible avoid creating new SQL instance by using the global one passed in
 | 
			
		||||
        if sql is None:
 | 
			
		||||
| 
						 | 
				
			
			@ -312,7 +314,7 @@ class Database:
 | 
			
		|||
 | 
			
		||||
        tables=self.cursor.execute(self.sql.query['list_tables'])
 | 
			
		||||
        tables=self.cursor.fetchall()
 | 
			
		||||
        for table in (u'Actions', u'Autorates', u'Backings', u'Gametypes', u'Hands', u'HandsActions', u'HandsPlayers', u'HudCache', u'Players', u'RawHands', u'RawTourneys', u'Settings', u'Sites', u'TourneyTypes', u'Tourneys', u'TourneysPlayers'):
 | 
			
		||||
        for table in (u'Actions', u'Autorates', u'Backings', u'Gametypes', u'Hands', u'HandsActions', u'HandsPlayers', u'HudCache', u'SessionsCache', u'Players', u'RawHands', u'RawTourneys', u'Settings', u'Sites', u'TourneyTypes', u'Tourneys', u'TourneysPlayers'):
 | 
			
		||||
            print "table:", table
 | 
			
		||||
            result+="###################\nTable "+table+"\n###################\n"
 | 
			
		||||
            rows=self.cursor.execute(self.sql.query['get'+table])
 | 
			
		||||
| 
						 | 
				
			
			@ -1177,6 +1179,7 @@ class Database:
 | 
			
		|||
            c.execute(self.sql.query['createHandsPlayersTable'])
 | 
			
		||||
            c.execute(self.sql.query['createHandsActionsTable'])
 | 
			
		||||
            c.execute(self.sql.query['createHudCacheTable'])
 | 
			
		||||
            c.execute(self.sql.query['createSessionsCacheTable'])
 | 
			
		||||
            c.execute(self.sql.query['createBackingsTable'])
 | 
			
		||||
            c.execute(self.sql.query['createRawHands'])
 | 
			
		||||
            c.execute(self.sql.query['createRawTourneys'])
 | 
			
		||||
| 
						 | 
				
			
			@ -1967,52 +1970,134 @@ class Database:
 | 
			
		|||
                #print "DEBUG: Successfully updated HudCacho using UPDATE"
 | 
			
		||||
                pass
 | 
			
		||||
            
 | 
			
		||||
    def storeSessionsCache(self, pids, starttime, pdata):
 | 
			
		||||
    def storeSessionsCache(self, pids, startTime, game, pdata):
 | 
			
		||||
        """Update cached sessions. If update fails because no record exists, do an insert."""
 | 
			
		||||
        #In development
 | 
			
		||||
        pass
 | 
			
		||||
        
 | 
			
		||||
        THRESHOLD = timedelta(seconds=int(self.sessionTimeout * 60)) #convert minutes to seconds
 | 
			
		||||
        bigBet = int(Decimal(game['bb'])*200)
 | 
			
		||||
        
 | 
			
		||||
        check_sessionscache = self.sql.query['check_sessionscache']
 | 
			
		||||
        check_sessionscache = check_sessionscache.replace('%s', self.sql.query['placeholder'])
 | 
			
		||||
        update_sessionscache = self.sql.query['update_sessionscache']
 | 
			
		||||
        update_sessionscache = update_sessionscache.replace('%s', self.sql.query['placeholder'])
 | 
			
		||||
        update_sessionscache_start = self.sql.query['update_sessionscache_start']
 | 
			
		||||
        update_sessionscache_start = update_sessionscache_start.replace('%s', self.sql.query['placeholder'])
 | 
			
		||||
        update_sessionscache_end = self.sql.query['update_sessionscache_end']
 | 
			
		||||
        update_sessionscache_end = update_sessionscache_end.replace('%s', self.sql.query['placeholder'])
 | 
			
		||||
        insert_sessionscache = self.sql.query['insert_sessionscache']
 | 
			
		||||
        insert_sessionscache = insert_sessionscache.replace('%s', self.sql.query['placeholder'])
 | 
			
		||||
        merge_sessionscache = self.sql.query['merge_sessionscache']
 | 
			
		||||
        merge_sessionscache = merge_sessionscache.replace('%s', self.sql.query['placeholder'])
 | 
			
		||||
        delete_sessions = self.sql.query['delete_sessions']
 | 
			
		||||
        delete_sessions = delete_sessions.replace('%s', self.sql.query['placeholder'])
 | 
			
		||||
        
 | 
			
		||||
        try:
 | 
			
		||||
            # derive list of program owner's player ids
 | 
			
		||||
            self.hero = {}                               # name of program owner indexed by site id
 | 
			
		||||
            self.hero_ids = []
 | 
			
		||||
                                                         # make sure at least two values in list
 | 
			
		||||
                                                         # so that tuple generation creates doesn't use
 | 
			
		||||
                                                         # () or (1,) style
 | 
			
		||||
            for site in self.config.get_supported_sites():
 | 
			
		||||
                result = self.get_site_id(site)
 | 
			
		||||
                if result:
 | 
			
		||||
                    site_id = result[0][0]
 | 
			
		||||
                    self.hero[site_id] = self.config.supported_sites[site].screen_name
 | 
			
		||||
                    p_id = self.get_player_id(self.config, site, self.hero[site_id])
 | 
			
		||||
                    if p_id:
 | 
			
		||||
                        self.hero_ids.append(int(p_id))
 | 
			
		||||
 | 
			
		||||
        #update_sessionscache = self.sql.query['update_sessionscache']
 | 
			
		||||
        #update_sessionscache = update_sessionscache.replace('%s', self.sql.query['placeholder'])
 | 
			
		||||
        #insert_sessionscache = self.sql.query['insert_sessionscache']
 | 
			
		||||
        #insert_sessionscache = insert_sessionscache.replace('%s', self.sql.query['placeholder'])
 | 
			
		||||
        #merge_sessionscache = self.sql.query['merge_sessionscache']
 | 
			
		||||
        #merge_sessionscache = merge_sessionscache.replace('%s', self.sql.query['placeholder'])
 | 
			
		||||
        except:
 | 
			
		||||
            err = traceback.extract_tb(sys.exc_info()[2])[-1]
 | 
			
		||||
            print _("Error aquiring hero ids:"), str(sys.exc_value)
 | 
			
		||||
            print err
 | 
			
		||||
 | 
			
		||||
        #print "DEBUG: %s %s %s" %(hid, pids, pdata)
 | 
			
		||||
        #inserts = []
 | 
			
		||||
        #for p in pdata:
 | 
			
		||||
            #line = [0]*5
 | 
			
		||||
        inserts = []
 | 
			
		||||
        for p in pdata:
 | 
			
		||||
            if pids[p] in self.hero_ids:
 | 
			
		||||
                line = [0]*5
 | 
			
		||||
    
 | 
			
		||||
                if (game['type']=='ring'): line[0] = 1 # count ring hands
 | 
			
		||||
                if (game['type']=='tour'): line[1] = 1 # count tour hands
 | 
			
		||||
                if (game['type']=='ring'): line[2] = pdata[p]['totalProfit']
 | 
			
		||||
                if (game['type']=='ring'): line[3] = float(Decimal(pdata[p]['totalProfit'])/Decimal(bigBet))
 | 
			
		||||
                line[4] = startTime
 | 
			
		||||
                inserts.append(line)
 | 
			
		||||
 | 
			
		||||
            #line[0] = 1 # HDs
 | 
			
		||||
            #line[1] = pdata[p]['totalProfit']
 | 
			
		||||
        cursor = self.get_cursor()
 | 
			
		||||
 | 
			
		||||
        for row in inserts:
 | 
			
		||||
            check = []
 | 
			
		||||
            check.append(row[-1]-THRESHOLD)
 | 
			
		||||
            check.append(row[-1]+THRESHOLD)
 | 
			
		||||
            num = cursor.execute(check_sessionscache, check)
 | 
			
		||||
            log.info(_("check yurself: '%s'") % (num.rowcount))
 | 
			
		||||
            
 | 
			
		||||
            #line[2] = pids[p]    # playerId
 | 
			
		||||
            #line[3] = sessionStart
 | 
			
		||||
            #line[4] = sessionEnd
 | 
			
		||||
            #inserts.append(line)
 | 
			
		||||
 | 
			
		||||
 | 
			
		||||
        #cursor = self.get_cursor()
 | 
			
		||||
 | 
			
		||||
        #for row in inserts:
 | 
			
		||||
            # Try to do the update first:
 | 
			
		||||
            #num = cursor.execute(update_sessionscache, row)
 | 
			
		||||
            #print "DEBUG: values: %s" % row[-3:]
 | 
			
		||||
            # Test statusmessage to see if update worked, do insert if not
 | 
			
		||||
            # num is a cursor in sqlite
 | 
			
		||||
            #if ((self.backend == self.PGSQL and cursor.statusmessage != "UPDATE 1")
 | 
			
		||||
                    #or (self.backend == self.MYSQL_INNODB and num == 0)
 | 
			
		||||
                    #or (self.backend == self.SQLITE and num.rowcount == 0)):
 | 
			
		||||
                #move the last 6 items in WHERE clause of row from the end of the array
 | 
			
		||||
            if ((self.backend == self.PGSQL and cursor.statusmessage == "UPDATE 1")
 | 
			
		||||
                    or (self.backend == self.MYSQL_INNODB and num == 1)
 | 
			
		||||
                    or (self.backend == self.SQLITE and num.rowcount == 1)):
 | 
			
		||||
                update = row + row[-1:]
 | 
			
		||||
                mid = cursor.execute(update_sessionscache, update)
 | 
			
		||||
                log.info(_("update '%s' rows, no change to session times ") % str(mid.rowcount))
 | 
			
		||||
                if ((self.backend == self.PGSQL and cursor.statusmessage != "UPDATE 1")
 | 
			
		||||
                    or (self.backend == self.MYSQL_INNODB and mid == 0)
 | 
			
		||||
                    or (self.backend == self.SQLITE and mid.rowcount == 0)):
 | 
			
		||||
                    update_start = row[-1:] + row + check
 | 
			
		||||
                    start = cursor.execute(update_sessionscache_start, update_start)
 | 
			
		||||
                    log.info(_("update '%s' rows, and updated sessionStart") % str(start.rowcount))
 | 
			
		||||
                    if ((self.backend == self.PGSQL and cursor.statusmessage != "UPDATE 1")
 | 
			
		||||
                        or (self.backend == self.MYSQL_INNODB and start == 0)
 | 
			
		||||
                        or (self.backend == self.SQLITE and start.rowcount == 0)):
 | 
			
		||||
                        update_end = row[-1:] + row + check
 | 
			
		||||
                        end = cursor.execute(update_sessionscache_end, update_end)
 | 
			
		||||
                        log.info(_("update '%s' rows, and updated sessionEnd") % str(end.rowcount))
 | 
			
		||||
                    else:
 | 
			
		||||
                        pass
 | 
			
		||||
                else:
 | 
			
		||||
                    pass
 | 
			
		||||
            elif ((self.backend == self.PGSQL and cursor.statusmessage != "UPDATE 1" and "UPDATE" in cursor.statusmessage)
 | 
			
		||||
                    or (self.backend == self.MYSQL_INNODB and num > 1)
 | 
			
		||||
                    or (self.backend == self.SQLITE and num.rowcount > 1)):
 | 
			
		||||
                log.info(_("multiple matches"))
 | 
			
		||||
                pass
 | 
			
		||||
                #merge_sessionscache
 | 
			
		||||
                cursor.execute(merge_sessionscache, check)
 | 
			
		||||
                merge = cursor.fetchone()
 | 
			
		||||
                cursor.execute(delete_sessions, check)
 | 
			
		||||
                cursor.execute(insert_sessionscache, merge)
 | 
			
		||||
                update = row + row[-1:]
 | 
			
		||||
                mid = cursor.execute(update_sessionscache, update)
 | 
			
		||||
                log.info(_("update '%s' rows, no change to session times ") % str(mid.rowcount))
 | 
			
		||||
                if ((self.backend == self.PGSQL and cursor.statusmessage != "UPDATE 1")
 | 
			
		||||
                    or (self.backend == self.MYSQL_INNODB and mid == 0)
 | 
			
		||||
                    or (self.backend == self.SQLITE and mid.rowcount == 0)):
 | 
			
		||||
                    update_start = row[-1:] + row + check
 | 
			
		||||
                    start = cursor.execute(update_sessionscache_start, update_start)
 | 
			
		||||
                    log.info(_("update '%s' rows, and updated sessionStart") % str(start.rowcount))
 | 
			
		||||
                    if ((self.backend == self.PGSQL and cursor.statusmessage != "UPDATE 1")
 | 
			
		||||
                        or (self.backend == self.MYSQL_INNODB and start == 0)
 | 
			
		||||
                        or (self.backend == self.SQLITE and start.rowcount == 0)):
 | 
			
		||||
                        update_end = row[-1:] + row + check
 | 
			
		||||
                        end = cursor.execute(update_sessionscache_end, update_end)
 | 
			
		||||
                        log.info(_("update '%s' rows, and updated sessionEnd") % str(end.rowcount))
 | 
			
		||||
                    else:
 | 
			
		||||
                        pass
 | 
			
		||||
                else:
 | 
			
		||||
                    pass
 | 
			
		||||
                
 | 
			
		||||
            elif ((self.backend == self.PGSQL and cursor.statusmessage != "UPDATE 1")
 | 
			
		||||
                    or (self.backend == self.MYSQL_INNODB and num == 0)
 | 
			
		||||
                    or (self.backend == self.SQLITE and num.rowcount == 0)):
 | 
			
		||||
                #move the last 2 items in WHERE clause of row from the end of the array
 | 
			
		||||
                # to the beginning for the INSERT statement
 | 
			
		||||
                #print "DEBUG: using INSERT: %s" % num
 | 
			
		||||
                #row = row[-3:] + row[:-3]
 | 
			
		||||
                #num = cursor.execute(insert_sessionscache, row)
 | 
			
		||||
                #print "DEBUG: Successfully(?: %s) updated HudCacho using INSERT" % num
 | 
			
		||||
            #else:
 | 
			
		||||
                #print "DEBUG: Successfully updated HudCacho using UPDATE"
 | 
			
		||||
                #pass
 | 
			
		||||
                insert = row + row[-1:]
 | 
			
		||||
                insert = insert[-2:] + insert[:-2]
 | 
			
		||||
                log.info(_("insert row: '%s'") % (insert))
 | 
			
		||||
                cursor.execute(insert_sessionscache, insert)
 | 
			
		||||
            else:
 | 
			
		||||
                pass
 | 
			
		||||
 | 
			
		||||
    def isDuplicate(self, gametypeID, siteHandNo):
 | 
			
		||||
        dup = False
 | 
			
		||||
| 
						 | 
				
			
			
 | 
			
		|||
| 
						 | 
				
			
			@ -280,7 +280,7 @@ db: a connected Database object"""
 | 
			
		|||
        db.storeHudCache(self.dbid_gt, self.dbid_pids, self.startTime, self.stats.getHandsPlayers())
 | 
			
		||||
        
 | 
			
		||||
    def updateSessionsCache(self, db):
 | 
			
		||||
        db.storeSessionsCache(self.dbid_pids, self.startTime, self.stats.getHandsPlayers())
 | 
			
		||||
        db.storeSessionsCache(self.dbid_pids, self.startTime, self.gametype, self.stats.getHandsPlayers())
 | 
			
		||||
 | 
			
		||||
    def select(self, handId):
 | 
			
		||||
        """ Function to create Hand object from database """
 | 
			
		||||
| 
						 | 
				
			
			
 | 
			
		|||
| 
						 | 
				
			
			@ -1355,7 +1355,42 @@ class Sql:
 | 
			
		|||
                        street3Raises INT,
 | 
			
		||||
                        street4Raises INT)
 | 
			
		||||
                        """
 | 
			
		||||
                        
 | 
			
		||||
        ################################
 | 
			
		||||
        # Create SessionsCache
 | 
			
		||||
        ################################
 | 
			
		||||
 | 
			
		||||
        if db_server == 'mysql':
 | 
			
		||||
            self.query['createSessionsCacheTable'] = """CREATE TABLE SessionsCache (
 | 
			
		||||
                        id BIGINT UNSIGNED AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
 | 
			
		||||
                        sessionStart DATETIME NOT NULL,
 | 
			
		||||
                        sessionEnd DATETIME NOT NULL,
 | 
			
		||||
                        ringHDs INT NOT NULL,
 | 
			
		||||
                        tourHDs INT NOT NULL,
 | 
			
		||||
                        totalProfit INT NOT NULL,
 | 
			
		||||
                        bigBets FLOAT UNSIGNED NOT NULL)
 | 
			
		||||
 | 
			
		||||
                        ENGINE=INNODB"""
 | 
			
		||||
        elif db_server == 'postgresql':
 | 
			
		||||
            self.query['createSessionsCacheTable'] = """CREATE TABLE SessionsCache (
 | 
			
		||||
                        id BIGSERIAL, PRIMARY KEY (id),
 | 
			
		||||
                        sessionStart REAL NOT NULL,
 | 
			
		||||
                        sessionEnd REAL NOT NULL,
 | 
			
		||||
                        ringHDs INT NOT NULL,
 | 
			
		||||
                        tourHDs INT NOT NULL,
 | 
			
		||||
                        totalProfit INT NOT NULL,
 | 
			
		||||
                        bigBets FLOAT NOT NULL)
 | 
			
		||||
                        """
 | 
			
		||||
        elif db_server == 'sqlite':
 | 
			
		||||
            self.query['createSessionsCacheTable'] = """CREATE TABLE SessionsCache (
 | 
			
		||||
                        id INTEGER PRIMARY KEY,
 | 
			
		||||
                        sessionStart REAL NOT NULL,
 | 
			
		||||
                        sessionEnd REAL NOT NULL,
 | 
			
		||||
                        ringHDs INT NOT NULL,
 | 
			
		||||
                        tourHDs INT NOT NULL,
 | 
			
		||||
                        totalProfit INT NOT NULL,
 | 
			
		||||
                        bigBets REAL UNSIGNED NOT NULL)
 | 
			
		||||
                        """
 | 
			
		||||
 | 
			
		||||
        if db_server == 'mysql':
 | 
			
		||||
            self.query['addTourneyIndex'] = """ALTER TABLE Tourneys ADD UNIQUE INDEX siteTourneyNo(siteTourneyNo, tourneyTypeId)"""
 | 
			
		||||
| 
						 | 
				
			
			@ -3971,6 +4006,69 @@ class Sql:
 | 
			
		|||
            AND   (case when tourneyTypeId is NULL then 1 else 
 | 
			
		||||
                   (case when tourneyTypeId+0=%s then 1 else 0 end) end)=1
 | 
			
		||||
            AND   styleKey=%s"""
 | 
			
		||||
            
 | 
			
		||||
        self.query['check_sessionscache'] = """
 | 
			
		||||
            UPDATE SessionsCache SET
 | 
			
		||||
            sessionStart=sessionStart,
 | 
			
		||||
            sessionEnd=sessionEnd,
 | 
			
		||||
            ringHDs=ringHDs,
 | 
			
		||||
            tourHDs=tourHDs,
 | 
			
		||||
            totalProfit=totalProfit,
 | 
			
		||||
            bigBets=bigBets
 | 
			
		||||
        WHERE sessionEnd>=%s
 | 
			
		||||
        AND sessionStart<=%s"""
 | 
			
		||||
 | 
			
		||||
        self.query['insert_sessionscache'] = """
 | 
			
		||||
            INSERT INTO SessionsCache (
 | 
			
		||||
                sessionStart,
 | 
			
		||||
                sessionEnd,
 | 
			
		||||
                ringHDs,
 | 
			
		||||
                tourHDs,
 | 
			
		||||
                totalProfit,
 | 
			
		||||
                bigBets)
 | 
			
		||||
            VALUES (%s, %s, %s, %s, %s, %s)"""
 | 
			
		||||
 | 
			
		||||
        self.query['update_sessionscache_start'] = """
 | 
			
		||||
            UPDATE SessionsCache SET
 | 
			
		||||
            sessionStart=%s,
 | 
			
		||||
            ringHDs=ringHDs+%s,
 | 
			
		||||
            tourHDs=tourHDs+%s,
 | 
			
		||||
            totalProfit=totalProfit+%s,
 | 
			
		||||
            bigBets=bigBets+%s
 | 
			
		||||
        WHERE sessionStart>%s
 | 
			
		||||
        AND sessionEnd>=%s
 | 
			
		||||
        AND sessionStart<=%s"""
 | 
			
		||||
        
 | 
			
		||||
        self.query['update_sessionscache_end'] = """
 | 
			
		||||
            UPDATE SessionsCache SET
 | 
			
		||||
            sessionEnd=%s,
 | 
			
		||||
            ringHDs=ringHDs+%s,
 | 
			
		||||
            tourHDs=tourHDs+%s,
 | 
			
		||||
            totalProfit=totalProfit+%s,
 | 
			
		||||
            bigBets=bigBets+%s
 | 
			
		||||
        WHERE sessionEnd<%s
 | 
			
		||||
        AND sessionEnd>=%s
 | 
			
		||||
        AND sessionStart<=%s"""
 | 
			
		||||
        
 | 
			
		||||
        self.query['update_sessionscache'] = """
 | 
			
		||||
            UPDATE SessionsCache SET
 | 
			
		||||
            ringHDs=ringHDs+%s,
 | 
			
		||||
            tourHDs=tourHDs+%s,
 | 
			
		||||
            totalProfit=totalProfit+%s,
 | 
			
		||||
            bigBets=bigBets+%s
 | 
			
		||||
        WHERE sessionStart<=%s
 | 
			
		||||
        AND sessionEnd>=%s"""
 | 
			
		||||
        
 | 
			
		||||
        self.query['merge_sessionscache'] = """
 | 
			
		||||
            SELECT min(sessionStart), max(sessionEnd), sum(ringHDs), sum(tourHDs), sum(totalProfit), sum(bigBets)
 | 
			
		||||
            FROM SessionsCache
 | 
			
		||||
        WHERE sessionStart>=%s 
 | 
			
		||||
        AND sessionEnd<=%s"""
 | 
			
		||||
        
 | 
			
		||||
        self.query['delete_sessions'] = """
 | 
			
		||||
            DELETE FROM SessionsCache
 | 
			
		||||
        WHERE sessionStart>=%s
 | 
			
		||||
        AND sessionEnd<=%s"""
 | 
			
		||||
 | 
			
		||||
        self.query['get_hero_hudcache_start'] = """select min(hc.styleKey)
 | 
			
		||||
                                                   from HudCache hc
 | 
			
		||||
| 
						 | 
				
			
			
 | 
			
		|||
		Loading…
	
		Reference in New Issue
	
	Block a user