diff --git a/pyfpdb/FpdbSQLQueries.py b/pyfpdb/FpdbSQLQueries.py
new file mode 100644
index 00000000..7c1e2ec5
--- /dev/null
+++ b/pyfpdb/FpdbSQLQueries.py
@@ -0,0 +1,609 @@
+#!/usr/bin/python
+
+#Copyright 2008 Steffen Jobbagy-Felso
+#This program is free software: you can redistribute it and/or modify
+#it under the terms of the GNU Affero General Public License as published by
+#the Free Software Foundation, version 3 of the License.
+#
+#This program is distributed in the hope that it will be useful,
+#but WITHOUT ANY WARRANTY; without even the implied warranty of
+#MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
+#GNU General Public License for more details.
+#
+#You should have received a copy of the GNU Affero General Public License
+#along with this program. If not, see .
+#In the "official" distribution you can find the license in
+#agpl-3.0.txt in the docs folder of the package.
+
+
+############################################################################
+#
+# File for DB queries used in fpdb
+#
+
+import sys
+import os
+
+class FpdbSQLQueries:
+
+ def __init__(self, db):
+ self.query = {}
+ self.dbname = db
+
+#Boilerplate code.
+# if(self.dbname == 'MySQL InnoDB'):
+# self.query[''] = """ """
+# elif(self.dbname == 'PostgreSQL'):
+# elif(self.dbname == 'SQLite'):
+
+
+ ################################
+ # List tables
+ ################################
+ if(self.dbname == 'MySQL InnoDB'):
+ self.query['list_tables'] = """SHOW TABLES"""
+ elif(self.dbname == 'PostgreSQL'):
+ self.query['list_tables'] = """SELECT table_name FROM information_schema.tables WHERE table_schema = 'public'"""
+ elif(self.dbname == 'SQLite'):
+ self.query['list_tables'] = """ """
+
+ ##################################################################
+ # Drop Tables - MySQL, PostgreSQL and SQLite all share same syntax
+ ##################################################################
+
+ if(self.dbname == 'MySQL InnoDB') or (self.dbname == 'PostgreSQL') or (self.dbname == 'SQLite'):
+ self.query['drop_table'] = """DROP TABLE IF EXISTS """
+
+
+ ################################
+ # Create Tables
+ ################################
+
+ ################################
+ # Create Settings
+ ################################
+ if(self.dbname == 'MySQL InnoDB'):
+ self.query['createSettingsTable'] = """CREATE TABLE Settings (
+ version SMALLINT NOT NULL)
+ ENGINE=INNODB"""
+ elif(self.dbname == 'PostgreSQL'):
+ self.query['createSettingsTable'] = """CREATE TABLE Settings (version SMALLINT)"""
+
+ elif(self.dbname == 'SQLite'):
+ #Probably doesn't work.
+ self.query['createSettingsTable'] = """ """
+
+
+ ################################
+ # Create Sites
+ ################################
+
+ if(self.dbname == 'MySQL InnoDB'):
+ self.query['createSitesTable'] = """CREATE TABLE Sites (
+ id SMALLINT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
+ name varchar(32) NOT NULL,
+ currency char(3) NOT NULL)
+ ENGINE=INNODB"""
+ elif(self.dbname == 'PostgreSQL'):
+ self.query['createSitesTable'] = """CREATE TABLE Sites (
+ id SERIAL UNIQUE, PRIMARY KEY (id),
+ name varchar(32),
+ currency char(3))"""
+ elif(self.dbname == 'SQLite'):
+ self.query['createSitesTable'] = """ """
+
+
+ ################################
+ # Create Gametypes
+ ################################
+
+ if(self.dbname == 'MySQL InnoDB'):
+ self.query['createGametypesTable'] = """CREATE TABLE Gametypes (
+ id SMALLINT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
+ siteId SMALLINT UNSIGNED NOT NULL, FOREIGN KEY (siteId) REFERENCES Sites(id),
+ type char(4) NOT NULL,
+ base char(4) NOT NULL,
+ category varchar(9) NOT NULL,
+ limitType char(2) NOT NULL,
+ hiLo char(1) NOT NULL,
+ smallBlind int,
+ bigBlind int,
+ smallBet int NOT NULL,
+ bigBet int NOT NULL)
+ ENGINE=INNODB"""
+ elif(self.dbname == 'PostgreSQL'):
+ self.query['createGametypesTable'] = """CREATE TABLE Gametypes (
+ id SERIAL UNIQUE, PRIMARY KEY (id),
+ siteId INTEGER, FOREIGN KEY (siteId) REFERENCES Sites(id),
+ type char(4),
+ base char(4),
+ category varchar(9),
+ limitType char(2),
+ hiLo char(1),
+ smallBlind int,
+ bigBlind int,
+ smallBet int,
+ bigBet int)"""
+ elif(self.dbname == 'SQLite'):
+ self.query['createGametypesTable'] = """ """
+
+
+ ################################
+ # Create Players
+ ################################
+
+ if(self.dbname == 'MySQL InnoDB'):
+ self.query['createPlayersTable'] = """CREATE TABLE Players (
+ id INT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
+ name VARCHAR(32) CHARACTER SET utf8 NOT NULL,
+ siteId SMALLINT UNSIGNED NOT NULL, FOREIGN KEY (siteId) REFERENCES Sites(id),
+ comment text,
+ commentTs DATETIME)
+ ENGINE=INNODB"""
+ elif(self.dbname == 'PostgreSQL'):
+ self.query['createPlayersTable'] = """CREATE TABLE Players (
+ id SERIAL UNIQUE, PRIMARY KEY (id),
+ name VARCHAR(32),
+ siteId INTEGER, FOREIGN KEY (siteId) REFERENCES Sites(id),
+ comment text,
+ commentTs timestamp without time zone)"""
+ elif(self.dbname == 'SQLite'):
+ self.query['createPlayersTable'] = """ """
+
+
+ ################################
+ # Create Autorates
+ ################################
+
+ if(self.dbname == 'MySQL InnoDB'):
+ self.query['createAutoratesTable'] = """CREATE TABLE Autorates (
+ id BIGINT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
+ playerId INT UNSIGNED NOT NULL, FOREIGN KEY (playerId) REFERENCES Players(id),
+ gametypeId SMALLINT UNSIGNED NOT NULL, FOREIGN KEY (gametypeId) REFERENCES Gametypes(id),
+ description varchar(50) NOT NULL,
+ shortDesc char(8) NOT NULL,
+ ratingTime DATETIME NOT NULL,
+ handCount int NOT NULL)
+ ENGINE=INNODB"""
+ elif(self.dbname == 'PostgreSQL'):
+ self.query['createAutoratesTable'] = """CREATE TABLE Autorates (
+ id BIGSERIAL UNIQUE, PRIMARY KEY (id),
+ playerId INT, FOREIGN KEY (playerId) REFERENCES Players(id),
+ gametypeId INT, FOREIGN KEY (gametypeId) REFERENCES Gametypes(id),
+ description varchar(50),
+ shortDesc char(8),
+ ratingTime timestamp without time zone,
+ handCount int)"""
+ elif(self.dbname == 'SQLite'):
+ self.query['createAutoratesTable'] = """ """
+
+
+ ################################
+ # Create Hands
+ ################################
+
+ if(self.dbname == 'MySQL InnoDB'):
+ self.query['createHandsTable'] = """CREATE TABLE Hands (
+ id BIGINT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
+ tableName VARCHAR(20) NOT NULL,
+ siteHandNo BIGINT NOT NULL,
+ gametypeId SMALLINT UNSIGNED NOT NULL, FOREIGN KEY (gametypeId) REFERENCES Gametypes(id),
+ handStart DATETIME NOT NULL,
+ importTime DATETIME NOT NULL,
+ seats SMALLINT NOT NULL,
+ maxSeats SMALLINT NOT NULL,
+ comment TEXT,
+ commentTs DATETIME)
+ ENGINE=INNODB"""
+ elif(self.dbname == 'PostgreSQL'):
+ self.query['createHandsTable'] = """CREATE TABLE Hands (
+ id BIGSERIAL UNIQUE, PRIMARY KEY (id),
+ tableName VARCHAR(20),
+ siteHandNo BIGINT,
+ gametypeId INT, FOREIGN KEY (gametypeId) REFERENCES Gametypes(id),
+ handStart timestamp without time zone,
+ importTime timestamp without time zone,
+ seats SMALLINT,
+ maxSeats SMALLINT,
+ comment TEXT,
+ commentTs timestamp without time zone)"""
+ elif(self.dbname == 'SQLite'):
+ self.query['createHandsTable'] = """ """
+
+
+ ################################
+ # Create Gametypes
+ ################################
+
+ if(self.dbname == 'MySQL InnoDB'):
+ self.query['createBoardCardsTable'] = """CREATE TABLE BoardCards (
+ id BIGINT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
+ handId BIGINT UNSIGNED NOT NULL, FOREIGN KEY (handId) REFERENCES Hands(id),
+ card1Value smallint NOT NULL,
+ card1Suit char(1) NOT NULL,
+ card2Value smallint NOT NULL,
+ card2Suit char(1) NOT NULL,
+ card3Value smallint NOT NULL,
+ card3Suit char(1) NOT NULL,
+ card4Value smallint NOT NULL,
+ card4Suit char(1) NOT NULL,
+ card5Value smallint NOT NULL,
+ card5Suit char(1) NOT NULL)
+ ENGINE=INNODB"""
+ elif(self.dbname == 'PostgreSQL'):
+ self.query['createBoardCardsTable'] = """CREATE TABLE BoardCards (
+ id BIGSERIAL UNIQUE, PRIMARY KEY (id),
+ handId BIGINT, FOREIGN KEY (handId) REFERENCES Hands(id),
+ card1Value smallint,
+ card1Suit char(1),
+ card2Value smallint,
+ card2Suit char(1),
+ card3Value smallint,
+ card3Suit char(1),
+ card4Value smallint,
+ card4Suit char(1),
+ card5Value smallint,
+ card5Suit char(1))"""
+ elif(self.dbname == 'SQLite'):
+ self.query['createBoardCardsTable'] = """ """
+
+
+ ################################
+ # Create TourneyTypes
+ ################################
+
+ if(self.dbname == 'MySQL InnoDB'):
+ self.query['createTourneyTypesTable'] = """CREATE TABLE TourneyTypes (
+ id SMALLINT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
+ siteId SMALLINT UNSIGNED NOT NULL, FOREIGN KEY (siteId) REFERENCES Sites(id),
+ buyin INT NOT NULL,
+ fee INT NOT NULL,
+ knockout INT NOT NULL,
+ rebuyOrAddon BOOLEAN NOT NULL)
+ ENGINE=INNODB"""
+ elif(self.dbname == 'PostgreSQL'):
+ self.query['createTourneyTypesTable'] = """CREATE TABLE TourneyTypes (
+ id SERIAL, PRIMARY KEY (id),
+ siteId INT, FOREIGN KEY (siteId) REFERENCES Sites(id),
+ buyin INT,
+ fee INT,
+ knockout INT,
+ rebuyOrAddon BOOLEAN)"""
+ elif(self.dbname == 'SQLite'):
+ self.query['createTourneyTypesTable'] = """ """
+
+
+ ################################
+ # Create Tourneys
+ ################################
+
+ if(self.dbname == 'MySQL InnoDB'):
+ self.query['createTourneysTable'] = """CREATE TABLE Tourneys (
+ id INT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
+ tourneyTypeId SMALLINT UNSIGNED NOT NULL, FOREIGN KEY (tourneyTypeId) REFERENCES TourneyTypes(id),
+ siteTourneyNo BIGINT NOT NULL,
+ entries INT NOT NULL,
+ prizepool INT NOT NULL,
+ startTime DATETIME NOT NULL,
+ comment TEXT,
+ commentTs DATETIME)
+ ENGINE=INNODB"""
+ elif(self.dbname == 'PostgreSQL'):
+ self.query['createTourneysTable'] = """CREATE TABLE Tourneys (
+ id SERIAL UNIQUE, PRIMARY KEY (id),
+ tourneyTypeId INT, FOREIGN KEY (tourneyTypeId) REFERENCES TourneyTypes(id),
+ siteTourneyNo BIGINT,
+ entries INT,
+ prizepool INT,
+ startTime timestamp without time zone,
+ comment TEXT,
+ commentTs timestamp without time zone)"""
+ elif(self.dbname == 'SQLite'):
+ self.query['createTourneysTable'] = """ """
+
+ ################################
+ # Create HandsPlayers
+ ################################
+
+ if(self.dbname == 'MySQL InnoDB'):
+ self.query['createHandsPlayersTable'] = """CREATE TABLE HandsPlayers (
+ id BIGINT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
+ handId BIGINT UNSIGNED NOT NULL, FOREIGN KEY (handId) REFERENCES Hands(id),
+ playerId INT UNSIGNED NOT NULL, FOREIGN KEY (playerId) REFERENCES Players(id),
+ startCash INT NOT NULL,
+ position CHAR(1),
+ seatNo SMALLINT NOT NULL,
+ ante INT,
+
+ card1Value smallint NOT NULL,
+ card1Suit char(1) NOT NULL,
+ card2Value smallint NOT NULL,
+ card2Suit char(1) NOT NULL,
+ card3Value smallint,
+ card3Suit char(1),
+ card4Value smallint,
+ card4Suit char(1),
+ card5Value smallint,
+ card5Suit char(1),
+ card6Value smallint,
+ card6Suit char(1),
+ card7Value smallint,
+ card7Suit char(1),
+
+ winnings int NOT NULL,
+ rake int NOT NULL,
+ comment text,
+ commentTs DATETIME,
+
+ tourneysPlayersId BIGINT UNSIGNED, FOREIGN KEY (tourneysPlayersId) REFERENCES TourneysPlayers(id))
+ ENGINE=INNODB"""
+ elif(self.dbname == 'PostgreSQL'):
+ self.query['createHandsPlayersTable'] = """CREATE TABLE HandsPlayers (
+ id BIGSERIAL UNIQUE, PRIMARY KEY (id),
+ handId BIGINT, FOREIGN KEY (handId) REFERENCES Hands(id),
+ playerId INT, FOREIGN KEY (playerId) REFERENCES Players(id),
+ startCash INT,
+ position CHAR(1),
+ seatNo SMALLINT,
+ ante INT,
+
+ card1Value smallint,
+ card1Suit char(1),
+ card2Value smallint,
+ card2Suit char(1),
+ card3Value smallint,
+ card3Suit char(1),
+ card4Value smallint,
+ card4Suit char(1),
+ card5Value smallint,
+ card5Suit char(1),
+ card6Value smallint,
+ card6Suit char(1),
+ card7Value smallint,
+ card7Suit char(1),
+
+ winnings int,
+ rake int,
+ comment text,
+ commentTs timestamp without time zone,
+ tourneysPlayersId BIGINT, FOREIGN KEY (tourneysPlayersId) REFERENCES TourneysPlayers(id))"""
+ elif(self.dbname == 'SQLite'):
+ self.query['createHandsPlayersTable'] = """ """
+
+
+ ################################
+ # Create TourneysPlayers
+ ################################
+
+ if(self.dbname == 'MySQL InnoDB'):
+ self.query['createTourneysPlayersTable'] = """CREATE TABLE TourneysPlayers (
+ id BIGINT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
+ tourneyId INT UNSIGNED NOT NULL, FOREIGN KEY (tourneyId) REFERENCES Tourneys(id),
+ playerId INT UNSIGNED NOT NULL, FOREIGN KEY (playerId) REFERENCES Players(id),
+ payinAmount INT NOT NULL,
+ rank INT NOT NULL,
+ winnings INT NOT NULL,
+ comment TEXT,
+ commentTs DATETIME)
+ ENGINE=INNODB"""
+ elif(self.dbname == 'PostgreSQL'):
+ self.query['createTourneysPlayersTable'] = """CREATE TABLE TourneysPlayers (
+ id BIGSERIAL UNIQUE, PRIMARY KEY (id),
+ tourneyId INT, FOREIGN KEY (tourneyId) REFERENCES Tourneys(id),
+ playerId INT, FOREIGN KEY (playerId) REFERENCES Players(id),
+ payinAmount INT,
+ rank INT,
+ winnings INT,
+ comment TEXT,
+ commentTs timestamp without time zone)"""
+ elif(self.dbname == 'SQLite'):
+ self.query['createTourneysPlayersTable'] = """ """
+
+
+ ################################
+ # Create HandsActions
+ ################################
+
+ if(self.dbname == 'MySQL InnoDB'):
+ self.query['createHandsActionsTable'] = """CREATE TABLE HandsActions (
+ id BIGINT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
+ handPlayerId BIGINT UNSIGNED NOT NULL, FOREIGN KEY (handPlayerId) REFERENCES HandsPlayers(id),
+ street SMALLINT NOT NULL,
+ actionNo SMALLINT NOT NULL,
+ action CHAR(5) NOT NULL,
+ allIn BOOLEAN NOT NULL,
+ amount INT NOT NULL,
+ comment TEXT,
+ commentTs DATETIME)
+ ENGINE=INNODB"""
+ elif(self.dbname == 'PostgreSQL'):
+ self.query['createHandsActionsTable'] = """CREATE TABLE HandsActions (
+ id BIGSERIAL UNIQUE, PRIMARY KEY (id),
+ handPlayerId BIGINT, FOREIGN KEY (handPlayerId) REFERENCES HandsPlayers(id),
+ street SMALLINT,
+ actionNo SMALLINT,
+ action CHAR(5),
+ allIn BOOLEAN,
+ amount INT,
+ comment TEXT,
+ commentTs timestamp without time zone)"""
+ elif(self.dbname == 'SQLite'):
+ self.query['createHandsActionsTable'] = """ """
+
+
+ ################################
+ # Create HudCache
+ ################################
+
+ if(self.dbname == 'MySQL InnoDB'):
+ self.query['createHudCacheTable'] = """CREATE TABLE HudCache (
+ id BIGINT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
+ gametypeId SMALLINT UNSIGNED NOT NULL, FOREIGN KEY (gametypeId) REFERENCES Gametypes(id),
+ playerId INT UNSIGNED NOT NULL, FOREIGN KEY (playerId) REFERENCES Players(id),
+ activeSeats SMALLINT NOT NULL,
+ position CHAR(1),
+ tourneyTypeId SMALLINT UNSIGNED NOT NULL, FOREIGN KEY (tourneyTypeId) REFERENCES TourneyTypes(id),
+
+ HDs INT NOT NULL,
+ street0VPI INT NOT NULL,
+ street0Aggr INT NOT NULL,
+ street0_3B4BChance INT NOT NULL,
+ street0_3B4BDone INT NOT NULL,
+
+ street1Seen INT NOT NULL,
+ street2Seen INT NOT NULL,
+ street3Seen INT NOT NULL,
+ street4Seen INT NOT NULL,
+ sawShowdown INT NOT NULL,
+
+ street1Aggr INT NOT NULL,
+ street2Aggr INT NOT NULL,
+ street3Aggr INT NOT NULL,
+ street4Aggr INT NOT NULL,
+
+ otherRaisedStreet1 INT NOT NULL,
+ otherRaisedStreet2 INT NOT NULL,
+ otherRaisedStreet3 INT NOT NULL,
+ otherRaisedStreet4 INT NOT NULL,
+ foldToOtherRaisedStreet1 INT NOT NULL,
+ foldToOtherRaisedStreet2 INT NOT NULL,
+ foldToOtherRaisedStreet3 INT NOT NULL,
+ foldToOtherRaisedStreet4 INT NOT NULL,
+ wonWhenSeenStreet1 FLOAT NOT NULL,
+ wonAtSD FLOAT NOT NULL,
+
+ stealAttemptChance INT NOT NULL,
+ stealAttempted INT NOT NULL,
+ foldBbToStealChance INT NOT NULL,
+ foldedBbToSteal INT NOT NULL,
+ foldSbToStealChance INT NOT NULL,
+ foldedSbToSteal INT NOT NULL,
+
+ street1CBChance INT NOT NULL,
+ street1CBDone INT NOT NULL,
+ street2CBChance INT NOT NULL,
+ street2CBDone INT NOT NULL,
+ street3CBChance INT NOT NULL,
+ street3CBDone INT NOT NULL,
+ street4CBChance INT NOT NULL,
+ street4CBDone INT NOT NULL,
+
+ foldToStreet1CBChance INT NOT NULL,
+ foldToStreet1CBDone INT NOT NULL,
+ foldToStreet2CBChance INT NOT NULL,
+ foldToStreet2CBDone INT NOT NULL,
+ foldToStreet3CBChance INT NOT NULL,
+ foldToStreet3CBDone INT NOT NULL,
+ foldToStreet4CBChance INT NOT NULL,
+ foldToStreet4CBDone INT NOT NULL,
+
+ totalProfit INT NOT NULL,
+
+ street1CheckCallRaiseChance INT NOT NULL,
+ street1CheckCallRaiseDone INT NOT NULL,
+ street2CheckCallRaiseChance INT NOT NULL,
+ street2CheckCallRaiseDone INT NOT NULL,
+ street3CheckCallRaiseChance INT NOT NULL,
+ street3CheckCallRaiseDone INT NOT NULL,
+ street4CheckCallRaiseChance INT NOT NULL,
+ street4CheckCallRaiseDone INT NOT NULL)
+ ENGINE=INNODB"""
+ elif(self.dbname == 'PostgreSQL'):
+ self.query['createHudCacheTable'] = """CREATE TABLE HudCache (
+ id BIGSERIAL UNIQUE, PRIMARY KEY (id),
+ gametypeId INT, FOREIGN KEY (gametypeId) REFERENCES Gametypes(id),
+ playerId INT, FOREIGN KEY (playerId) REFERENCES Players(id),
+ activeSeats SMALLINT,
+ position CHAR(1),
+ tourneyTypeId INT, FOREIGN KEY (tourneyTypeId) REFERENCES TourneyTypes(id),
+
+ HDs INT,
+ street0VPI INT,
+ street0Aggr INT,
+ street0_3B4BChance INT,
+ street0_3B4BDone INT,
+ street1Seen INT,
+ street2Seen INT,
+ street3Seen INT,
+ street4Seen INT,
+ sawShowdown INT,
+ street1Aggr INT,
+ street2Aggr INT,
+ street3Aggr INT,
+ street4Aggr INT,
+ otherRaisedStreet1 INT,
+ otherRaisedStreet2 INT,
+ otherRaisedStreet3 INT,
+ otherRaisedStreet4 INT,
+ foldToOtherRaisedStreet1 INT,
+ foldToOtherRaisedStreet2 INT,
+ foldToOtherRaisedStreet3 INT,
+ foldToOtherRaisedStreet4 INT,
+ wonWhenSeenStreet1 FLOAT,
+ wonAtSD FLOAT,
+
+ stealAttemptChance INT,
+ stealAttempted INT,
+ foldBbToStealChance INT,
+ foldedBbToSteal INT,
+ foldSbToStealChance INT,
+ foldedSbToSteal INT,
+
+ street1CBChance INT,
+ street1CBDone INT,
+ street2CBChance INT,
+ street2CBDone INT,
+ street3CBChance INT,
+ street3CBDone INT,
+ street4CBChance INT,
+ street4CBDone INT,
+
+ foldToStreet1CBChance INT,
+ foldToStreet1CBDone INT,
+ foldToStreet2CBChance INT,
+ foldToStreet2CBDone INT,
+ foldToStreet3CBChance INT,
+ foldToStreet3CBDone INT,
+ foldToStreet4CBChance INT,
+ foldToStreet4CBDone INT,
+
+ totalProfit INT,
+
+ street1CheckCallRaiseChance INT,
+ street1CheckCallRaiseDone INT,
+ street2CheckCallRaiseChance INT,
+ street2CheckCallRaiseDone INT,
+ street3CheckCallRaiseChance INT,
+ street3CheckCallRaiseDone INT,
+ street4CheckCallRaiseChance INT,
+ street4CheckCallRaiseDone INT)"""
+ elif(self.dbname == 'SQLite'):
+ self.query['createHudCacheTable'] = """ """
+
+
+if __name__== "__main__":
+ from optparse import OptionParser
+
+ print "FpdbSQLQueries starting from CLI"
+
+ #process CLI parameters
+ usage = "usage: %prog [options]"
+ parser = OptionParser()
+ parser.add_option("-t", "--type", dest="dbtype", help="Available 'MySQL InnoDB', 'PostgreSQL', 'SQLite'(default: MySQL InnoDB)", default="MySQL InnoDB")
+ parser.add_option("-s", "--show", action="store_true", dest="showsql", help="Show full SQL output")
+ parser.add_option("-v", "--verbose", action="store_true", dest="verbose")
+
+
+ (options, args) = parser.parse_args()
+
+ if options.verbose:
+ print """No additional output available in this file"""
+
+ obj = FpdbSQLQueries(options.dbtype)
+
+ print "Available Queries for '" + options.dbtype + "':"
+
+ for key in obj.query:
+ print " " + key
+ if options.showsql:
+ print obj.query[key]
diff --git a/pyfpdb/RegressionTest.py b/pyfpdb/RegressionTest.py
new file mode 100644
index 00000000..db1a88b9
--- /dev/null
+++ b/pyfpdb/RegressionTest.py
@@ -0,0 +1,76 @@
+#!/usr/bin/python
+
+#Copyright 2008 Steffen Jobbagy-Felso
+#This program is free software: you can redistribute it and/or modify
+#it under the terms of the GNU Affero General Public License as published by
+#the Free Software Foundation, version 3 of the License.
+#
+#This program is distributed in the hope that it will be useful,
+#but WITHOUT ANY WARRANTY; without even the implied warranty of
+#MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
+#GNU General Public License for more details.
+#
+#You should have received a copy of the GNU Affero General Public License
+#along with this program. If not, see .
+#In the "official" distribution you can find the license in
+#agpl-3.0.txt in the docs folder of the package.
+
+
+############################################################################
+#
+# File for Regression Testing fpdb
+#
+
+import os
+import sys
+
+import fpdb_db
+import FpdbSQLQueries
+
+import unittest
+
+class TestSequenceFunctions(unittest.TestCase):
+
+ def setUp(self):
+ """Configure MySQL settings/database and establish connection"""
+ self.mysql_settings={ 'db-host':"localhost", 'db-backend':2, 'db-databaseName':"fpdbtest", 'db-user':"fpdb", 'db-password':"fpdb"}
+ self.mysql_db = fpdb_db.fpdb_db()
+ self.mysql_db.connect(self.mysql_settings['db-backend'], self.mysql_settings['db-host'],
+ self.mysql_settings['db-databaseName'], self.mysql_settings['db-user'],
+ self.mysql_settings['db-password'])
+ self.mysqldict = FpdbSQLQueries.FpdbSQLQueries('MySQL InnoDB')
+
+ """Configure Postgres settings/database and establish connection"""
+ self.pg_settings={ 'db-host':"localhost", 'db-backend':3, 'db-databaseName':"fpdbtest", 'db-user':"fpdb", 'db-password':"fpdb"}
+ self.pg_db = fpdb_db.fpdb_db()
+ self.pg_db.connect(self.pg_settings['db-backend'], self.pg_settings['db-host'],
+ self.pg_settings['db-databaseName'], self.pg_settings['db-user'],
+ self.pg_settings['db-password'])
+ self.pgdict = FpdbSQLQueries.FpdbSQLQueries('PostgreSQL')
+
+
+ def testDatabaseConnection(self):
+ """Test all supported DBs"""
+ self.result = self.mysql_db.cursor.execute(self.mysqldict.query['list_tables'])
+ self.failUnless(self.result==13, "Number of tables in database incorrect. Expected 13 got " + str(self.result))
+
+ print self.pgdict.query['list_tables']
+
+ self.result = self.pg_db.cursor.execute(self.pgdict.query['list_tables'])
+ self.failUnless(self.result==13, "Number of tables in database incorrect. Expected 13 got " + str(self.result))
+
+ def testMySQLRecreateTables(self):
+ """Test droping then recreating fpdb table schema"""
+ self.mysql_db.recreate_tables()
+ self.result = self.mysql_db.cursor.execute("SHOW TABLES")
+ self.failUnless(self.result==13, "Number of tables in database incorrect. Expected 13 got " + str(self.result))
+
+ def testPostgresSQLRecreateTables(self):
+ """Test droping then recreating fpdb table schema"""
+ self.pg_db.recreate_tables()
+ self.result = self.pg_db.cursor.execute(self.pgdict.query['list_tables'])
+ self.failUnless(self.result==13, "Number of tables in database incorrect. Expected 13 got " + str(self.result))
+
+if __name__ == '__main__':
+ unittest.main()
+
diff --git a/pyfpdb/fpdb_db.py b/pyfpdb/fpdb_db.py
index 36e39ba9..92a5ed86 100644
--- a/pyfpdb/fpdb_db.py
+++ b/pyfpdb/fpdb_db.py
@@ -16,13 +16,16 @@
#agpl-3.0.txt in the docs folder of the package.
import os
+import re
import fpdb_simple
+import FpdbSQLQueries
class fpdb_db:
def __init__(self):
"""Simple constructor, doesnt really do anything"""
self.db=None
self.cursor=None
+ self.sql = {}
self.MYSQL_INNODB=2
self.PGSQL=3
self.SQLITE=4
@@ -44,6 +47,8 @@ class fpdb_db:
else:
raise fpdb_simple.FpdbError("unrecognised database backend:"+backend)
self.cursor=self.db.cursor()
+ # Set up query dictionary as early in the connection process as we can.
+ self.sql = FpdbSQLQueries.FpdbSQLQueries(self.get_backend_name())
self.wrongDbVersion=False
try:
self.cursor.execute("SELECT * FROM Settings")
@@ -56,20 +61,6 @@ class fpdb_db:
self.wrongDbVersion=True
#end def connect
- def create_table(self, string):
- """creates a table for the given string
- The string should the name of the table followed by the column list
- in brackets as if it were an SQL command. Do NOT include the "CREATE TABLES"
- bit at the beginning nor the ";" or ENGINE= at the end"""
- string="CREATE TABLE "+string
- if (self.backend==self.MYSQL_INNODB):
- string+=" ENGINE=INNODB"
- string+=";"
- #print "create_table, string:", string
- self.cursor.execute(string)
- self.db.commit()
- #end def create_table
-
def disconnect(self, due_to_error=False):
"""Disconnects the DB"""
if due_to_error:
@@ -85,57 +76,69 @@ class fpdb_db:
#print "started fpdb_db.reconnect"
self.disconnect(due_to_error)
self.connect(self.backend, self.host, self.database, self.user, self.password)
- #end def disconnect
+
+ def create_tables(self):
+ #todo: should detect and fail gracefully if tables already exist.
+ self.cursor.execute(self.sql.query['createSettingsTable'])
+ self.cursor.execute(self.sql.query['createSitesTable'])
+ self.cursor.execute(self.sql.query['createGametypesTable'])
+ self.cursor.execute(self.sql.query['createPlayersTable'])
+ self.cursor.execute(self.sql.query['createAutoratesTable'])
+ self.cursor.execute(self.sql.query['createHandsTable'])
+ self.cursor.execute(self.sql.query['createBoardCardsTable'])
+ self.cursor.execute(self.sql.query['createTourneyTypesTable'])
+ self.cursor.execute(self.sql.query['createTourneysTable'])
+ self.cursor.execute(self.sql.query['createTourneysPlayersTable'])
+ self.cursor.execute(self.sql.query['createHandsPlayersTable'])
+ self.cursor.execute(self.sql.query['createHandsActionsTable'])
+ self.cursor.execute(self.sql.query['createHudCacheTable'])
+ self.fillDefaultData()
+ self.db.commit()
+#end def disconnect
def drop_tables(self):
"""Drops the fpdb tables from the current db"""
- oldDbVersion=0
- try:
- self.cursor.execute("SELECT * FROM settings") #for alpha1
- oldDbVersion=self.cursor.fetchone()[0]
- except:# _mysql_exceptions.ProgrammingError:
- pass
- try:
- self.cursor.execute("SELECT * FROM Settings")
- oldDbVersion=self.cursor.fetchone()[0]
- except:# _mysql_exceptions.ProgrammingError:
- pass
-
- if oldDbVersion<=34:
- self.cursor.execute("DROP TABLE IF EXISTS settings;")
- self.cursor.execute("DROP TABLE IF EXISTS HudDataHoldemOmaha;")
- self.cursor.execute("DROP TABLE IF EXISTS autorates;")
- self.cursor.execute("DROP TABLE IF EXISTS board_cards;")
- self.cursor.execute("DROP TABLE IF EXISTS hands_actions;")
- self.cursor.execute("DROP TABLE IF EXISTS hands_players;")
- self.cursor.execute("DROP TABLE IF EXISTS hands;")
- self.cursor.execute("DROP TABLE IF EXISTS tourneys_players;")
- self.cursor.execute("DROP TABLE IF EXISTS tourneys;")
- self.cursor.execute("DROP TABLE IF EXISTS players;")
- self.cursor.execute("DROP TABLE IF EXISTS gametypes;")
- self.cursor.execute("DROP TABLE IF EXISTS sites;")
-
- if oldDbVersion>34 and oldDbVersion<=45:
- self.cursor.execute("DROP TABLE IF EXISTS HudDataHoldemOmaha;")
-
- self.cursor.execute("DROP TABLE IF EXISTS Settings;")
- self.cursor.execute("DROP TABLE IF EXISTS HudCache;")
- self.cursor.execute("DROP TABLE IF EXISTS Autorates;")
- self.cursor.execute("DROP TABLE IF EXISTS BoardCards;")
- self.cursor.execute("DROP TABLE IF EXISTS HandsActions;")
- self.cursor.execute("DROP TABLE IF EXISTS HandsPlayers;")
- self.cursor.execute("DROP TABLE IF EXISTS Hands;")
- self.cursor.execute("DROP TABLE IF EXISTS TourneysPlayers;")
- self.cursor.execute("DROP TABLE IF EXISTS Tourneys;")
- self.cursor.execute("DROP TABLE IF EXISTS Players;")
- self.cursor.execute("DROP TABLE IF EXISTS Gametypes;")
- if oldDbVersion>45 and oldDbVersion<=51:
- self.cursor.execute("DROP TABLE IF EXISTS TourneysGametypes;")
- self.cursor.execute("DROP TABLE IF EXISTS TourneyTypes;")
- self.cursor.execute("DROP TABLE IF EXISTS Sites;")
-
- self.db.commit()
+
+ if(self.get_backend_name() == 'MySQL InnoDB'):
+ #Databases with FOREIGN KEY support need this switched of before you can drop tables
+ self.drop_referencial_integrity()
+
+ # Query the DB to see what tables exist
+ self.cursor.execute(self.sql.query['list_tables'])
+ for table in self.cursor:
+ self.cursor.execute(self.sql.query['drop_table'] + table[0])
+ elif(self.get_backend_name() == 'PostgreSQL'):
+ self.db.commit()# I have no idea why this makes the query work--REB 07OCT2008
+ self.cursor.execute(self.sql.query['list_tables'])
+ tables = self.cursor.fetchall()
+ for table in tables:
+ self.cursor.execute(self.sql.query['drop_table'] + table[0] + ' cascade')
+ elif(self.get_backend_name() == 'SQLite'):
+ #todo: sqlite version here
+ print "Empty function here"
+
+ self.db.commit()
#end def drop_tables
+
+ def drop_referencial_integrity(self):
+ """Update all tables to remove foreign keys"""
+
+ self.cursor.execute(self.sql.query['list_tables'])
+ result = self.cursor.fetchall()
+
+ for i in range(len(result)):
+ self.cursor.execute("SHOW CREATE TABLE " + result[i][0])
+ inner = self.cursor.fetchall()
+
+ for j in range(len(inner)):
+ # result[i][0] - Table name
+ # result[i][1] - CREATE TABLE parameters
+ #Searching for CONSTRAINT `tablename_ibfk_1`
+ for m in re.finditer('(ibfk_[0-9]+)', inner[j][1]):
+ key = "`" + inner[j][0] + "_" + m.group() + "`"
+ self.cursor.execute("ALTER TABLE " + inner[j][0] + " DROP FOREIGN KEY " + key)
+ self.db.commit()
+ #end drop_referencial_inegrity
def get_backend_name(self):
"""Returns the name of the currently used backend"""
@@ -153,243 +156,17 @@ class fpdb_db:
def fillDefaultData(self):
self.cursor.execute("INSERT INTO Settings VALUES (118);")
- self.cursor.execute("INSERT INTO Sites VALUES (DEFAULT, \"Full Tilt Poker\", 'USD');")
- self.cursor.execute("INSERT INTO Sites VALUES (DEFAULT, \"PokerStars\", 'USD');")
+ self.cursor.execute("INSERT INTO Sites VALUES (DEFAULT, 'Full Tilt Poker', 'USD');")
+ self.cursor.execute("INSERT INTO Sites VALUES (DEFAULT, 'PokerStars', 'USD');")
self.cursor.execute("INSERT INTO TourneyTypes VALUES (DEFAULT, 1, 0, 0, 0, False);")
#end def fillDefaultData
def recreate_tables(self):
"""(Re-)creates the tables of the current DB"""
- if self.backend == 3:
-# postgresql
- print "recreating tables in postgres db"
- schema_file = open('schema.postgres.sql', 'r')
- schema = schema_file.read()
- schema_file.close()
- curse = self.db.cursor()
-# curse.executemany(schema, [1, 2])
- for sql in schema.split(';'):
- sql = sql.rstrip()
- if sql == '':
- continue
- curse.execute(sql)
- #self.fillDefaultData()
- self.db.commit()
- curse.close()
- return
-
self.drop_tables()
-
- self.create_table("""Settings (
- version SMALLINT NOT NULL)""")
-
- self.create_table("""Sites (
- id SMALLINT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
- name varchar(32) NOT NULL,
- currency char(3) NOT NULL)""")
-
- self.create_table("""Gametypes (
- id SMALLINT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
- siteId SMALLINT UNSIGNED NOT NULL, FOREIGN KEY (siteId) REFERENCES Sites(id),
- type char(4) NOT NULL,
- base char(4) NOT NULL,
- category varchar(9) NOT NULL,
- limitType char(2) NOT NULL,
- hiLo char(1) NOT NULL,
- smallBlind int,
- bigBlind int,
- smallBet int NOT NULL,
- bigBet int NOT NULL)""")
- #NOT NULL not set for small/bigBlind as they are not existent in all games
-
- self.create_table("""Players (
- id INT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
- name VARCHAR(32) CHARACTER SET utf8 NOT NULL,
- siteId SMALLINT UNSIGNED NOT NULL, FOREIGN KEY (siteId) REFERENCES Sites(id),
- comment text,
- commentTs DATETIME)""")
-
- self.create_table("""Autorates (
- id BIGINT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
- playerId INT UNSIGNED NOT NULL, FOREIGN KEY (playerId) REFERENCES Players(id),
- gametypeId SMALLINT UNSIGNED NOT NULL, FOREIGN KEY (gametypeId) REFERENCES Gametypes(id),
- description varchar(50) NOT NULL,
- shortDesc char(8) NOT NULL,
- ratingTime DATETIME NOT NULL,
- handCount int NOT NULL)""")
-
- self.create_table("""Hands (
- id BIGINT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
- tableName VARCHAR(20) NOT NULL,
- siteHandNo BIGINT NOT NULL,
- gametypeId SMALLINT UNSIGNED NOT NULL, FOREIGN KEY (gametypeId) REFERENCES Gametypes(id),
- handStart DATETIME NOT NULL,
- importTime DATETIME NOT NULL,
- seats SMALLINT NOT NULL,
- maxSeats SMALLINT NOT NULL,
- comment TEXT,
- commentTs DATETIME)""")
-
- self.create_table("""BoardCards (
- id BIGINT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
- handId BIGINT UNSIGNED NOT NULL, FOREIGN KEY (handId) REFERENCES Hands(id),
- card1Value smallint NOT NULL,
- card1Suit char(1) NOT NULL,
- card2Value smallint NOT NULL,
- card2Suit char(1) NOT NULL,
- card3Value smallint NOT NULL,
- card3Suit char(1) NOT NULL,
- card4Value smallint NOT NULL,
- card4Suit char(1) NOT NULL,
- card5Value smallint NOT NULL,
- card5Suit char(1) NOT NULL)""")
-
- self.create_table("""TourneyTypes (
- id SMALLINT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
- siteId SMALLINT UNSIGNED NOT NULL, FOREIGN KEY (siteId) REFERENCES Sites(id),
- buyin INT NOT NULL,
- fee INT NOT NULL,
- knockout INT NOT NULL,
- rebuyOrAddon BOOLEAN NOT NULL)""")
-
- self.create_table("""Tourneys (
- id INT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
- tourneyTypeId SMALLINT UNSIGNED NOT NULL, FOREIGN KEY (tourneyTypeId) REFERENCES TourneyTypes(id),
- siteTourneyNo BIGINT NOT NULL,
- entries INT NOT NULL,
- prizepool INT NOT NULL,
- startTime DATETIME NOT NULL,
- comment TEXT,
- commentTs DATETIME)""")
-
- self.create_table("""TourneysPlayers (
- id BIGINT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
- tourneyId INT UNSIGNED NOT NULL, FOREIGN KEY (tourneyId) REFERENCES Tourneys(id),
- playerId INT UNSIGNED NOT NULL, FOREIGN KEY (playerId) REFERENCES Players(id),
- payinAmount INT NOT NULL,
- rank INT NOT NULL,
- winnings INT NOT NULL,
- comment TEXT,
- commentTs DATETIME)""")
-
- self.create_table("""HandsPlayers (
- id BIGINT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
- handId BIGINT UNSIGNED NOT NULL, FOREIGN KEY (handId) REFERENCES Hands(id),
- playerId INT UNSIGNED NOT NULL, FOREIGN KEY (playerId) REFERENCES Players(id),
- startCash INT NOT NULL,
- position CHAR(1),
- seatNo SMALLINT NOT NULL,
- ante INT,
-
- card1Value smallint NOT NULL,
- card1Suit char(1) NOT NULL,
- card2Value smallint NOT NULL,
- card2Suit char(1) NOT NULL,
- card3Value smallint,
- card3Suit char(1),
- card4Value smallint,
- card4Suit char(1),
- card5Value smallint,
- card5Suit char(1),
- card6Value smallint,
- card6Suit char(1),
- card7Value smallint,
- card7Suit char(1),
-
- winnings int NOT NULL,
- rake int NOT NULL,
- comment text,
- commentTs DATETIME,
-
- tourneysPlayersId BIGINT UNSIGNED, FOREIGN KEY (tourneysPlayersId) REFERENCES TourneysPlayers(id))""")
- #NOT NULL not set on cards 3-7 as they dont exist in all games
-
- self.create_table("""HandsActions (
- id BIGINT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
- handPlayerId BIGINT UNSIGNED NOT NULL, FOREIGN KEY (handPlayerId) REFERENCES HandsPlayers(id),
- street SMALLINT NOT NULL,
- actionNo SMALLINT NOT NULL,
- action CHAR(5) NOT NULL,
- allIn BOOLEAN NOT NULL,
- amount INT NOT NULL,
- comment TEXT,
- commentTs DATETIME)""")
-
- self.create_table("""HudCache (
- id BIGINT UNSIGNED UNIQUE AUTO_INCREMENT NOT NULL, PRIMARY KEY (id),
- gametypeId SMALLINT UNSIGNED NOT NULL, FOREIGN KEY (gametypeId) REFERENCES Gametypes(id),
- playerId INT UNSIGNED NOT NULL, FOREIGN KEY (playerId) REFERENCES Players(id),
- activeSeats SMALLINT NOT NULL,
- position CHAR(1),
- tourneyTypeId SMALLINT UNSIGNED NOT NULL, FOREIGN KEY (tourneyTypeId) REFERENCES TourneyTypes(id),
-
- HDs INT NOT NULL,
- street0VPI INT NOT NULL,
- street0Aggr INT NOT NULL,
- street0_3B4BChance INT NOT NULL,
- street0_3B4BDone INT NOT NULL,
-
- street1Seen INT NOT NULL,
- street2Seen INT NOT NULL,
- street3Seen INT NOT NULL,
- street4Seen INT NOT NULL,
- sawShowdown INT NOT NULL,
-
- street1Aggr INT NOT NULL,
- street2Aggr INT NOT NULL,
- street3Aggr INT NOT NULL,
- street4Aggr INT NOT NULL,
-
- otherRaisedStreet1 INT NOT NULL,
- otherRaisedStreet2 INT NOT NULL,
- otherRaisedStreet3 INT NOT NULL,
- otherRaisedStreet4 INT NOT NULL,
- foldToOtherRaisedStreet1 INT NOT NULL,
- foldToOtherRaisedStreet2 INT NOT NULL,
- foldToOtherRaisedStreet3 INT NOT NULL,
- foldToOtherRaisedStreet4 INT NOT NULL,
- wonWhenSeenStreet1 FLOAT NOT NULL,
- wonAtSD FLOAT NOT NULL,
-
- stealAttemptChance INT NOT NULL,
- stealAttempted INT NOT NULL,
- foldBbToStealChance INT NOT NULL,
- foldedBbToSteal INT NOT NULL,
- foldSbToStealChance INT NOT NULL,
- foldedSbToSteal INT NOT NULL,
-
- street1CBChance INT NOT NULL,
- street1CBDone INT NOT NULL,
- street2CBChance INT NOT NULL,
- street2CBDone INT NOT NULL,
- street3CBChance INT NOT NULL,
- street3CBDone INT NOT NULL,
- street4CBChance INT NOT NULL,
- street4CBDone INT NOT NULL,
-
- foldToStreet1CBChance INT NOT NULL,
- foldToStreet1CBDone INT NOT NULL,
- foldToStreet2CBChance INT NOT NULL,
- foldToStreet2CBDone INT NOT NULL,
- foldToStreet3CBChance INT NOT NULL,
- foldToStreet3CBDone INT NOT NULL,
- foldToStreet4CBChance INT NOT NULL,
- foldToStreet4CBDone INT NOT NULL,
-
- totalProfit INT NOT NULL,
-
- street1CheckCallRaiseChance INT NOT NULL,
- street1CheckCallRaiseDone INT NOT NULL,
- street2CheckCallRaiseChance INT NOT NULL,
- street2CheckCallRaiseDone INT NOT NULL,
- street3CheckCallRaiseChance INT NOT NULL,
- street3CheckCallRaiseDone INT NOT NULL,
- street4CheckCallRaiseChance INT NOT NULL,
- street4CheckCallRaiseDone INT NOT NULL)""")
-
- self.fillDefaultData()
+ self.create_tables()
self.db.commit()
- print "finished recreating tables"
+ print "Finished recreating tables"
#end def recreate_tables
#end class fpdb_db