diff --git a/.gitignore b/.gitignore index 5acf6f7..7e43ff2 100644 --- a/.gitignore +++ b/.gitignore @@ -1,4 +1,5 @@ .*.swp +*.pyc config.toml tags doc diff --git a/config.ini.sample b/config.ini.sample index 4e4e66c..b2be7a3 100644 --- a/config.ini.sample +++ b/config.ini.sample @@ -27,6 +27,11 @@ timezone = US/Eastern # The name of the PostgreSQL database containing NFL data. database = nfldb +# The database search path setting +# if you create database in its own schema you want to add the +# schema name here +search_path = public + # The username and password for the database specified above. # The user should have permission to add, delete and remove data. # Also, the user should have permission to create/alter/drop tables, diff --git a/nfldb/db.py b/nfldb/db.py index 66a218f..20ea596 100644 --- a/nfldb/db.py +++ b/nfldb/db.py @@ -34,6 +34,14 @@ else: _config_home = path.join(home, '.config') +def pfx(c, ddl): + """ + Replace token with specific prefix to allow absolute + references to resources""" + if c.schema is not None: + return ddl.replace('_PFX_', c.schema) + else: + return ddl.replace('_PFX_', 'public') def config(config_path=''): """ @@ -63,6 +71,7 @@ def config(config_path=''): return { 'timezone': cp.get('pgsql', 'timezone'), 'database': cp.get('pgsql', 'database'), + 'search_path': cp.get('pgsql', 'search_path'), 'user': cp.get('pgsql', 'user'), 'password': cp.get('pgsql', 'password'), 'host': cp.get('pgsql', 'host'), @@ -74,7 +83,7 @@ def config(config_path=''): def connect(database=None, user=None, password=None, host=None, port=None, - timezone=None, config_path=''): + timezone=None, config_path='', search_path=None): """ Returns a `psycopg2._psycopg.connection` object from the `psycopg2.connect` function. If database is `None`, then `connect` @@ -106,10 +115,13 @@ def connect(database=None, user=None, password=None, host=None, port=None, timezone, database = conf['timezone'], conf['database'] user, password = conf['user'], conf['password'] host, port = conf['host'], conf['port'] + search_path = conf['search_path'] - conn = psycopg2.connect(database=database, user=user, password=password, - host=host, port=port) + if search_path is None: + search_path = 'public' + conn = (psycopg2.connect(database=database, user=user, password=password, + host=host, port=port), search_path) # Start the migration. Make sure if this is the initial setup that # the DB is empty. sversion = schema_version(conn) @@ -145,9 +157,9 @@ def schema_version(conn): """ with Tx(conn) as c: try: - c.execute('SELECT version FROM meta LIMIT 1', ['version']) + c.execute(pfx(c, 'SELECT version FROM _PFX_.meta LIMIT 1'), ['version']) except psycopg2.ProgrammingError: - conn.rollback() + conn[0].rollback() return 0 if c.rowcount == 0: return 0 @@ -203,10 +215,10 @@ def _is_empty(conn): database. """ with Tx(conn) as c: - c.execute(''' + c.execute(pfx(c, ''' SELECT COUNT(*) AS count FROM information_schema.tables - WHERE table_catalog = %s AND table_schema = 'public' - ''', [_db_name(conn)]) + WHERE table_catalog = %s AND table_schema = '_PFX_' + '''), [_db_name(conn[0])]) if c.fetchone()['count'] == 0: return True return False @@ -219,7 +231,7 @@ def _mogrify(cursor, xs): def _num_rows(cursor, table): """Returns the number of rows in table.""" - cursor.execute('SELECT COUNT(*) AS rowcount FROM %s' % table) + cursor.execute(pfx(cursor, 'SELECT COUNT(*) AS rowcount FROM _PFX_.%s') % table) return cursor.fetchone()['rowcount'] @@ -252,8 +264,11 @@ class Tx (object): (Or when interfacing with another part of the API that requires a database cursor.) """ - def __init__(self, psycho_conn, name=None, factory=None): + def __init__(self, conn, name=None, factory=None): """ + `conn` is a tuple containing a `psycho_conn` and the database + search path allowing nfldb to reside in its own schema + `psycho_conn` is a DB connection returned from `nfldb.connect`, `name` is passed as the `name` argument to the cursor constructor (for server-side cursors), and `factory` is passed @@ -264,20 +279,34 @@ def __init__(self, psycho_conn, name=None, factory=None): `psycopg2.extensions.cursor` (the default tuple cursor) can be much more efficient when fetching large result sets. """ + psycho_conn = conn[0] + schema = 'public' + search_path = 'public' + if conn[1] != 'public': + search_path = "%s,%s" % (conn[1], search_path) + schema = conn[1] + tstatus = psycho_conn.get_transaction_status() self.__name = name self.__nested = tstatus == TRANSACTION_STATUS_INTRANS self.__conn = psycho_conn + self.__search_path = search_path + self.__schema = schema self.__cursor = None self.__factory = factory if self.__factory is None: self.__factory = RealDictCursor def __enter__(self): - self.__cursor = self.__conn.cursor(name=self.__name, - cursor_factory=self.__factory) + if self.__name is None: + self.__cursor = self.__conn.cursor(cursor_factory=self.__factory) + else: + self.__cursor = self.__conn.cursor(name=self.__name, + cursor_factory=self.__factory) c = self.__cursor - + c.search_path = self.__search_path + c.schema = self.__schema + c.execute("SET search_path TO %s" % self.__search_path) #class _ (object): # def execute(self, *args, **kwargs): # c.execute(*args, **kwargs) @@ -299,7 +328,6 @@ def __exit__(self, typ, value, traceback): self.__conn.commit() return True - def _big_insert(cursor, table, datas): """ Given a database cursor, table name and a list of asssociation @@ -327,7 +355,7 @@ def vals(xs): return [v for _, v in xs] values = ', '.join(_mogrify(cursor, times(vals(data))) for data in datas) - cursor.execute('INSERT INTO %s (%s) VALUES %s' + cursor.execute(pfx(cursor, 'INSERT INTO _PFX_.%s (%s) VALUES %s') % (table, insert_fields, values)) @@ -362,17 +390,17 @@ def _upsert(cursor, table, data, pk): pk_cond = ' AND '.join(['%s = %s' % (k, '%s') for k, _ in pk]) q = ''' - UPDATE %s SET %s WHERE %s; + UPDATE _PFX_.%s SET %s WHERE %s; ''' % (table, update_set, pk_cond) q += ''' - INSERT INTO %s (%s) + INSERT INTO _PFX_.%s (%s) SELECT %s WHERE NOT EXISTS (SELECT 1 FROM %s WHERE %s) ''' % (table, insert_fields, insert_places, table, pk_cond) values = [v for _, v in data] pk_values = [v for _, v in pk] try: - cursor.execute(q, values + pk_values + values + pk_values) + cursor.execute(pfx(cursor, q), values + pk_values + values + pk_values) except psycopg2.ProgrammingError as e: print(cursor.query) raise e @@ -382,20 +410,19 @@ def _drop_stat_indexes(c): from nfldb.types import _play_categories, _player_categories for cat in _player_categories.values(): - c.execute('DROP INDEX play_player_in_%s' % cat) + c.execute(pfx(c, 'DROP INDEX _PFX_.play_player_in_%s') % cat) for cat in _play_categories.values(): - c.execute('DROP INDEX play_in_%s' % cat) + c.execute(pfx('DROP INDEX _PFX_.play_in_%s') % cat) def _create_stat_indexes(c): from nfldb.types import _play_categories, _player_categories for cat in _player_categories.values(): - c.execute('CREATE INDEX play_player_in_%s ON play_player (%s ASC)' + c.execute(pfx(c, 'CREATE INDEX play_player_in_%s ON _PFX_.play_player (%s ASC)') % (cat, cat)) for cat in _play_categories.values(): - c.execute('CREATE INDEX play_in_%s ON play (%s ASC)' % (cat, cat)) - + c.execute(pfx(c, 'CREATE INDEX play_in_%s ON _PFX_.play (%s ASC)') % (cat, cat)) # What follows are the migration functions. They follow the naming # convention "_migrate_{VERSION}" where VERSION is an integer that @@ -420,105 +447,104 @@ def _migrate(conn, to): with Tx(conn) as c: assert fname in globs, 'Migration function %d not defined.' % v globs[fname](c) - c.execute("UPDATE meta SET version = %s", (v,)) + c.execute(pfx(c,"UPDATE _PFX_.meta SET version = %s"), (v,)) def _migrate_1(c): - c.execute(''' - CREATE DOMAIN utctime AS timestamp with time zone + c.execute(pfx(c, ''' + CREATE DOMAIN _PFX_.utctime AS timestamp with time zone CHECK (EXTRACT(TIMEZONE FROM VALUE) = '0') - ''') - c.execute(''' - CREATE TABLE meta ( + ''')) + c.execute(pfx(c, ''' + CREATE TABLE _PFX_.meta ( version smallint, - last_roster_download utctime NOT NULL + last_roster_download _PFX_.utctime NOT NULL ) - ''') - c.execute(''' - INSERT INTO meta + ''')) + c.execute(pfx(c, ''' + INSERT INTO _PFX_.meta (version, last_roster_download) VALUES (1, '0001-01-01T00:00:00Z') - ''') + ''')) def _migrate_2(c): from nfldb.types import Enums, _play_categories, _player_categories - # Create some types and common constraints. - c.execute(''' - CREATE DOMAIN gameid AS character varying (10) + c.execute(pfx(c, ''' + CREATE DOMAIN _PFX_.gameid AS character varying (10) CHECK (char_length(VALUE) = 10) - ''') - c.execute(''' - CREATE DOMAIN usmallint AS smallint + ''')) + c.execute(pfx(c, ''' + CREATE DOMAIN _PFX_.usmallint AS smallint CHECK (VALUE >= 0) - ''') - c.execute(''' - CREATE DOMAIN game_clock AS smallint + ''')) + c.execute(pfx(c,''' + CREATE DOMAIN _PFX_.game_clock AS smallint CHECK (VALUE >= 0 AND VALUE <= 900) - ''') - c.execute(''' - CREATE DOMAIN field_offset AS smallint + ''')) + c.execute(pfx(c,''' + CREATE DOMAIN _PFX_.field_offset AS smallint CHECK (VALUE >= -50 AND VALUE <= 50) - ''') - - c.execute(''' - CREATE TYPE game_phase AS ENUM %s - ''' % _mogrify(c, Enums.game_phase)) - c.execute(''' - CREATE TYPE season_phase AS ENUM %s - ''' % _mogrify(c, Enums.season_phase)) - c.execute(''' - CREATE TYPE game_day AS ENUM %s - ''' % _mogrify(c, Enums.game_day)) - c.execute(''' - CREATE TYPE player_pos AS ENUM %s - ''' % _mogrify(c, Enums.player_pos)) - c.execute(''' - CREATE TYPE player_status AS ENUM %s - ''' % _mogrify(c, Enums.player_status)) - c.execute(''' - CREATE TYPE game_time AS ( - phase game_phase, - elapsed game_clock + ''')) + + c.execute(pfx(c, ''' + CREATE TYPE _PFX_.game_phase AS ENUM %s + ''') % _mogrify(c, Enums.game_phase)) + c.execute(pfx(c, ''' + CREATE TYPE _PFX_.season_phase AS ENUM %s + ''') % _mogrify(c, Enums.season_phase)) + c.execute(pfx(c, ''' + CREATE TYPE _PFX_.game_day AS ENUM %s + ''') % _mogrify(c, Enums.game_day)) + c.execute(pfx(c, ''' + CREATE TYPE _PFX_.player_pos AS ENUM %s + ''') % _mogrify(c, Enums.player_pos)) + c.execute(pfx(c, ''' + CREATE TYPE _PFX_.player_status AS ENUM %s + ''') % _mogrify(c, Enums.player_status)) + c.execute(pfx(c, ''' + CREATE TYPE _PFX_.game_time AS ( + phase _PFX_.game_phase, + elapsed _PFX_.game_clock ) - ''') - c.execute(''' - CREATE TYPE pos_period AS ( - elapsed usmallint + ''')) + c.execute(pfx(c, ''' + CREATE TYPE _PFX_.pos_period AS ( + elapsed _PFX_.usmallint ) - ''') - c.execute(''' - CREATE TYPE field_pos AS ( - pos field_offset + ''')) + c.execute(pfx(c, ''' + CREATE TYPE _PFX_.field_pos AS ( + pos _PFX_.field_offset ) - ''') + ''')) # Now that some types have been made, add current state to meta table. - c.execute(''' - ALTER TABLE meta - ADD season_type season_phase NULL, - ADD season_year usmallint NULL + c.execute(pfx(c, ''' + ALTER TABLE _PFX_.meta + ADD season_type _PFX_.season_phase NULL, + ADD season_year _PFX_.usmallint NULL CHECK (season_year >= 1960 AND season_year <= 2100), - ADD week usmallint NULL + ADD week _PFX_.usmallint NULL CHECK (week >= 1 AND week <= 25) - ''') + ''')) # Create the team table and populate it. - c.execute(''' - CREATE TABLE team ( + c.execute(pfx(c, ''' + CREATE TABLE _PFX_.team ( team_id character varying (3) NOT NULL, city character varying (50) NOT NULL, name character varying (50) NOT NULL, PRIMARY KEY (team_id) ) - ''') - c.execute(''' - INSERT INTO team (team_id, city, name) VALUES %s - ''' % (', '.join(_mogrify(c, team[0:3]) for team in nfldb.team.teams))) + ''')) + c.execute(pfx(c, ''' + INSERT INTO _PFX_.team (team_id, city, name) VALUES %s + ''') % (', '.join(_mogrify(c, team[0:3]) for team in nfldb.team.teams))) - c.execute(''' - CREATE TABLE player ( + c.execute(pfx(c, ''' + CREATE TABLE _PFX_.player ( player_id character varying (10) NOT NULL CHECK (char_length(player_id) = 10), gsis_name character varying (75) NULL, @@ -526,235 +552,235 @@ def _migrate_2(c): first_name character varying (100) NULL, last_name character varying (100) NULL, team character varying (3) NOT NULL, - position player_pos NOT NULL, + position _PFX_.player_pos NOT NULL, profile_id integer NULL, profile_url character varying (255) NULL, - uniform_number usmallint NULL, + uniform_number _PFX_.usmallint NULL, birthdate character varying (75) NULL, college character varying (255) NULL, height character varying (100) NULL, weight character varying (100) NULL, - years_pro usmallint NULL, - status player_status NOT NULL, + years_pro _PFX_.usmallint NULL, + status _PFX_.player_status NOT NULL, PRIMARY KEY (player_id), FOREIGN KEY (team) - REFERENCES team (team_id) + REFERENCES _PFX_.team (team_id) ON DELETE RESTRICT ON UPDATE CASCADE ) - ''') - c.execute(''' - CREATE TABLE game ( - gsis_id gameid NOT NULL, + ''')) + c.execute(pfx(c, ''' + CREATE TABLE _PFX_.game ( + gsis_id _PFX_.gameid NOT NULL, gamekey character varying (5) NULL, - start_time utctime NOT NULL, - week usmallint NOT NULL + start_time _PFX_.utctime NOT NULL, + week _PFX_.usmallint NOT NULL CHECK (week >= 1 AND week <= 25), - day_of_week game_day NOT NULL, - season_year usmallint NOT NULL + day_of_week _PFX_.game_day NOT NULL, + season_year _PFX_.usmallint NOT NULL CHECK (season_year >= 1960 AND season_year <= 2100), - season_type season_phase NOT NULL, + season_type _PFX_.season_phase NOT NULL, finished boolean NOT NULL, home_team character varying (3) NOT NULL, - home_score usmallint NOT NULL, - home_score_q1 usmallint NULL, - home_score_q2 usmallint NULL, - home_score_q3 usmallint NULL, - home_score_q4 usmallint NULL, - home_score_q5 usmallint NULL, - home_turnovers usmallint NOT NULL, + home_score _PFX_.usmallint NOT NULL, + home_score_q1 _PFX_.usmallint NULL, + home_score_q2 _PFX_.usmallint NULL, + home_score_q3 _PFX_.usmallint NULL, + home_score_q4 _PFX_.usmallint NULL, + home_score_q5 _PFX_.usmallint NULL, + home_turnovers _PFX_.usmallint NOT NULL, away_team character varying (3) NOT NULL, - away_score usmallint NOT NULL, - away_score_q1 usmallint NULL, - away_score_q2 usmallint NULL, - away_score_q3 usmallint NULL, - away_score_q4 usmallint NULL, - away_score_q5 usmallint NULL, - away_turnovers usmallint NOT NULL, - time_inserted utctime NOT NULL, - time_updated utctime NOT NULL, + away_score _PFX_.usmallint NOT NULL, + away_score_q1 _PFX_.usmallint NULL, + away_score_q2 _PFX_.usmallint NULL, + away_score_q3 _PFX_.usmallint NULL, + away_score_q4 _PFX_.usmallint NULL, + away_score_q5 _PFX_.usmallint NULL, + away_turnovers _PFX_.usmallint NOT NULL, + time_inserted _PFX_.utctime NOT NULL, + time_updated _PFX_.utctime NOT NULL, PRIMARY KEY (gsis_id), FOREIGN KEY (home_team) - REFERENCES team (team_id) + REFERENCES _PFX_.team (team_id) ON DELETE RESTRICT ON UPDATE CASCADE, FOREIGN KEY (away_team) - REFERENCES team (team_id) + REFERENCES _PFX_.team (team_id) ON DELETE RESTRICT ON UPDATE CASCADE ) - ''') - c.execute(''' - CREATE TABLE drive ( - gsis_id gameid NOT NULL, - drive_id usmallint NOT NULL, - start_field field_pos NULL, - start_time game_time NOT NULL, - end_field field_pos NULL, - end_time game_time NOT NULL, + ''')) + c.execute(pfx(c, ''' + CREATE TABLE _PFX_.drive ( + gsis_id _PFX_.gameid NOT NULL, + drive_id _PFX_.usmallint NOT NULL, + start_field _PFX_.field_pos NULL, + start_time _PFX_.game_time NOT NULL, + end_field _PFX_.field_pos NULL, + end_time _PFX_.game_time NOT NULL, pos_team character varying (3) NOT NULL, - pos_time pos_period NULL, - first_downs usmallint NOT NULL, + pos_time _PFX_.pos_period NULL, + first_downs _PFX_.usmallint NOT NULL, result text NULL, penalty_yards smallint NOT NULL, yards_gained smallint NOT NULL, - play_count usmallint NOT NULL, - time_inserted utctime NOT NULL, - time_updated utctime NOT NULL, + play_count _PFX_.usmallint NOT NULL, + time_inserted _PFX_.utctime NOT NULL, + time_updated _PFX_.utctime NOT NULL, PRIMARY KEY (gsis_id, drive_id), FOREIGN KEY (gsis_id) - REFERENCES game (gsis_id) + REFERENCES _PFX_.game (gsis_id) ON DELETE CASCADE, FOREIGN KEY (pos_team) - REFERENCES team (team_id) + REFERENCES _PFX_.team (team_id) ON DELETE RESTRICT ON UPDATE CASCADE ) - ''') + ''')) # I've taken the approach of using a sparse table to represent # sparse play statistic data. See issue #2: # https://github.com/BurntSushi/nfldb/issues/2 - c.execute(''' - CREATE TABLE play ( - gsis_id gameid NOT NULL, - drive_id usmallint NOT NULL, - play_id usmallint NOT NULL, - time game_time NOT NULL, + c.execute(pfx(c, ''' + CREATE TABLE _PFX_.play ( + gsis_id _PFX_.gameid NOT NULL, + drive_id _PFX_.usmallint NOT NULL, + play_id _PFX_.usmallint NOT NULL, + time _PFX_.game_time NOT NULL, pos_team character varying (3) NOT NULL, - yardline field_pos NULL, + yardline _PFX_.field_pos NULL, down smallint NULL CHECK (down >= 1 AND down <= 4), yards_to_go smallint NULL CHECK (yards_to_go >= 0 AND yards_to_go <= 100), description text NULL, note text NULL, - time_inserted utctime NOT NULL, - time_updated utctime NOT NULL, + time_inserted _PFX_.utctime NOT NULL, + time_updated _PFX_.utctime NOT NULL, %s, PRIMARY KEY (gsis_id, drive_id, play_id), FOREIGN KEY (gsis_id, drive_id) - REFERENCES drive (gsis_id, drive_id) + REFERENCES _PFX_.drive (gsis_id, drive_id) ON DELETE CASCADE, FOREIGN KEY (gsis_id) - REFERENCES game (gsis_id) + REFERENCES _PFX_.game (gsis_id) ON DELETE CASCADE, FOREIGN KEY (pos_team) - REFERENCES team (team_id) + REFERENCES _PFX_.team (team_id) ON DELETE RESTRICT ON UPDATE CASCADE ) - ''' % ', '.join([cat._sql_field for cat in _play_categories.values()])) + ''') % ', '.join([cat._sql_field for cat in _play_categories.values()])) - c.execute(''' - CREATE TABLE play_player ( - gsis_id gameid NOT NULL, - drive_id usmallint NOT NULL, - play_id usmallint NOT NULL, + c.execute(pfx(c, ''' + CREATE TABLE _PFX_.play_player ( + gsis_id _PFX_.gameid NOT NULL, + drive_id _PFX_.usmallint NOT NULL, + play_id _PFX_.usmallint NOT NULL, player_id character varying (10) NOT NULL, team character varying (3) NOT NULL, %s, PRIMARY KEY (gsis_id, drive_id, play_id, player_id), FOREIGN KEY (gsis_id, drive_id, play_id) - REFERENCES play (gsis_id, drive_id, play_id) + REFERENCES _PFX_.play (gsis_id, drive_id, play_id) ON DELETE CASCADE, FOREIGN KEY (gsis_id, drive_id) - REFERENCES drive (gsis_id, drive_id) + REFERENCES _PFX_.drive (gsis_id, drive_id) ON DELETE CASCADE, FOREIGN KEY (gsis_id) - REFERENCES game (gsis_id) + REFERENCES _PFX_.game (gsis_id) ON DELETE CASCADE, FOREIGN KEY (player_id) - REFERENCES player (player_id) + REFERENCES _PFX_.player (player_id) ON DELETE RESTRICT, FOREIGN KEY (team) - REFERENCES team (team_id) + REFERENCES _PFX_.team (team_id) ON DELETE RESTRICT ON UPDATE CASCADE ) - ''' % ', '.join(cat._sql_field for cat in _player_categories.values())) + ''') % ', '.join(cat._sql_field for cat in _player_categories.values())) def _migrate_3(c): _create_stat_indexes(c) - c.execute(''' - CREATE INDEX player_in_gsis_name ON player (gsis_name ASC); - CREATE INDEX player_in_full_name ON player (full_name ASC); - CREATE INDEX player_in_team ON player (team ASC); - CREATE INDEX player_in_position ON player (position ASC); - ''') - c.execute(''' - CREATE INDEX game_in_gamekey ON game (gamekey ASC); - CREATE INDEX game_in_start_time ON game (start_time ASC); - CREATE INDEX game_in_week ON game (week ASC); - CREATE INDEX game_in_day_of_week ON game (day_of_week ASC); - CREATE INDEX game_in_season_year ON game (season_year ASC); - CREATE INDEX game_in_season_type ON game (season_type ASC); - CREATE INDEX game_in_finished ON game (finished ASC); - CREATE INDEX game_in_home_team ON game (home_team ASC); - CREATE INDEX game_in_away_team ON game (away_team ASC); - CREATE INDEX game_in_home_score ON game (home_score ASC); - CREATE INDEX game_in_away_score ON game (away_score ASC); - CREATE INDEX game_in_home_turnovers ON game (home_turnovers ASC); - CREATE INDEX game_in_away_turnovers ON game (away_turnovers ASC); - ''') - c.execute(''' - CREATE INDEX drive_in_gsis_id ON drive (gsis_id ASC); - CREATE INDEX drive_in_drive_id ON drive (drive_id ASC); - CREATE INDEX drive_in_start_field ON drive + c.execute(pfx(c, ''' + CREATE INDEX player_in_gsis_name ON _PFX_.player (gsis_name ASC); + CREATE INDEX player_in_full_name ON _PFX_.player (full_name ASC); + CREATE INDEX player_in_team ON _PFX_.player (team ASC); + CREATE INDEX player_in_position ON _PFX_.player (position ASC); + ''')) + c.execute(pfx(c, ''' + CREATE INDEX game_in_gamekey ON _PFX_.game (gamekey ASC); + CREATE INDEX game_in_start_time ON _PFX_.game (start_time ASC); + CREATE INDEX game_in_week ON _PFX_.game (week ASC); + CREATE INDEX game_in_day_of_week ON _PFX_.game (day_of_week ASC); + CREATE INDEX game_in_season_year ON _PFX_.game (season_year ASC); + CREATE INDEX game_in_season_type ON _PFX_.game (season_type ASC); + CREATE INDEX game_in_finished ON _PFX_.game (finished ASC); + CREATE INDEX game_in_home_team ON _PFX_.game (home_team ASC); + CREATE INDEX game_in_away_team ON _PFX_.game (away_team ASC); + CREATE INDEX game_in_home_score ON _PFX_.game (home_score ASC); + CREATE INDEX game_in_away_score ON _PFX_.game (away_score ASC); + CREATE INDEX game_in_home_turnovers ON _PFX_.game (home_turnovers ASC); + CREATE INDEX game_in_away_turnovers ON _PFX_.game (away_turnovers ASC); + ''')) + c.execute(pfx(c, ''' + CREATE INDEX drive_in_gsis_id ON _PFX_.drive (gsis_id ASC); + CREATE INDEX drive_in_drive_id ON _PFX_.drive (drive_id ASC); + CREATE INDEX drive_in_start_field ON _PFX_.drive (((start_field).pos) ASC); - CREATE INDEX drive_in_end_field ON drive + CREATE INDEX drive_in_end_field ON _PFX_.drive (((end_field).pos) ASC); - CREATE INDEX drive_in_start_time ON drive + CREATE INDEX drive_in_start_time ON _PFX_.drive (((start_time).phase) ASC, ((start_time).elapsed) ASC); - CREATE INDEX drive_in_end_time ON drive + CREATE INDEX drive_in_end_time ON _PFX_.drive (((end_time).phase) ASC, ((end_time).elapsed) ASC); - CREATE INDEX drive_in_pos_team ON drive (pos_team ASC); - CREATE INDEX drive_in_pos_time ON drive + CREATE INDEX drive_in_pos_team ON _PFX_.drive (pos_team ASC); + CREATE INDEX drive_in_pos_time ON _PFX_.drive (((pos_time).elapsed) DESC); - CREATE INDEX drive_in_first_downs ON drive (first_downs DESC); - CREATE INDEX drive_in_penalty_yards ON drive (penalty_yards DESC); - CREATE INDEX drive_in_yards_gained ON drive (yards_gained DESC); - CREATE INDEX drive_in_play_count ON drive (play_count DESC); - ''') - c.execute(''' - CREATE INDEX play_in_gsis_id ON play (gsis_id ASC); - CREATE INDEX play_in_gsis_drive_id ON play (gsis_id ASC, drive_id ASC); - CREATE INDEX play_in_time ON play + CREATE INDEX drive_in_first_downs ON _PFX_.drive (first_downs DESC); + CREATE INDEX drive_in_penalty_yards ON _PFX_.drive (penalty_yards DESC); + CREATE INDEX drive_in_yards_gained ON _PFX_.drive (yards_gained DESC); + CREATE INDEX drive_in_play_count ON _PFX_.drive (play_count DESC); + ''')) + c.execute(pfx(c, ''' + CREATE INDEX play_in_gsis_id ON _PFX_.play (gsis_id ASC); + CREATE INDEX play_in_gsis_drive_id ON _PFX_.play (gsis_id ASC, drive_id ASC); + CREATE INDEX play_in_time ON _PFX_.play (((time).phase) ASC, ((time).elapsed) ASC); - CREATE INDEX play_in_pos_team ON play (pos_team ASC); - CREATE INDEX play_in_yardline ON play + CREATE INDEX play_in_pos_team ON _PFX_.play (pos_team ASC); + CREATE INDEX play_in_yardline ON _PFX_.play (((yardline).pos) ASC); - CREATE INDEX play_in_down ON play (down ASC); - CREATE INDEX play_in_yards_to_go ON play (yards_to_go DESC); - ''') - c.execute(''' - CREATE INDEX pp_in_gsis_id ON play_player (gsis_id ASC); - CREATE INDEX pp_in_player_id ON play_player (player_id ASC); - CREATE INDEX pp_in_gsis_drive_id ON play_player + CREATE INDEX play_in_down ON _PFX_.play (down ASC); + CREATE INDEX play_in_yards_to_go ON _PFX_.play (yards_to_go DESC); + ''')) + c.execute(pfx(c, ''' + CREATE INDEX pp_in_gsis_id ON _PFX_.play_player (gsis_id ASC); + CREATE INDEX pp_in_player_id ON _PFX_.play_player (player_id ASC); + CREATE INDEX pp_in_gsis_drive_id ON _PFX_.play_player (gsis_id ASC, drive_id ASC); - CREATE INDEX pp_in_gsis_drive_play_id ON play_player + CREATE INDEX pp_in_gsis_drive_play_id ON _PFX_.play_player (gsis_id ASC, drive_id ASC, play_id ASC); - CREATE INDEX pp_in_gsis_player_id ON play_player + CREATE INDEX pp_in_gsis_player_id ON _PFX_.play_player (gsis_id ASC, player_id ASC); - CREATE INDEX pp_in_team ON play_player (team ASC); - ''') + CREATE INDEX pp_in_team ON _PFX_.play_player (team ASC); + ''')) def _migrate_4(c): - c.execute(''' - UPDATE team SET city = 'New York' WHERE team_id IN ('NYG', 'NYJ'); - UPDATE team SET name = 'Giants' WHERE team_id = 'NYG'; - UPDATE team SET name = 'Jets' WHERE team_id = 'NYJ'; - ''') + c.execute(pfx(c, ''' + UPDATE _PFX_.team SET city = 'New York' WHERE team_id IN ('NYG', 'NYJ'); + UPDATE _PFX_.team SET name = 'Giants' WHERE team_id = 'NYG'; + UPDATE _PFX_.team SET name = 'Jets' WHERE team_id = 'NYJ'; + ''')) def _migrate_5(c): - c.execute(''' - UPDATE player SET weight = '0', height = '0' - ''') - c.execute(''' - ALTER TABLE player + c.execute(pfx(c, ''' + UPDATE _PFX_.player SET weight = '0', height = '0' + ''')) + c.execute(pfx(c, ''' + ALTER TABLE _PFX_.player ALTER COLUMN height TYPE usmallint USING height::usmallint, ALTER COLUMN weight TYPE usmallint USING weight::usmallint; - ''') + ''')) diff --git a/scripts/nfldb-update b/scripts/nfldb-update index af29868..9a7a2c3 100755 --- a/scripts/nfldb-update +++ b/scripts/nfldb-update @@ -403,7 +403,7 @@ if __name__ == '__main__': update(db, player_interval=args.player_interval) log('Closing database connection... ', end='') - db.close() + db[0].close() log('done.') log('FINISHED NFLDB UPDATE AT %s' % now())