Rework SQLite database handling to make the script more efficient

This commit is contained in:
Lucas Verney 2018-11-13 11:23:55 +01:00
parent 6773227ae1
commit aaa9b19cd3
1 changed files with 105 additions and 54 deletions

159
velib.py
View File

@ -1,11 +1,17 @@
#!/usr/bin/env python3 #!/usr/bin/env python3
import datetime import datetime
import json import json
import logging
import os import os
import pybikes import pybikes
import sqlite3 import sqlite3
import time import time
level = logging.WARNING
if os.environ.get('DEBUG', False):
level = logging.DEBUG
logging.basicConfig(level=level)
def db_init(db_name=None): def db_init(db_name=None):
""" """
@ -13,6 +19,7 @@ def db_init(db_name=None):
Returns a new connection. Returns a new connection.
""" """
logging.info('Initialize DB...')
now = datetime.datetime.now() now = datetime.datetime.now()
if db_name is None: if db_name is None:
db_name = "week_%s.db" % now.strftime("%V") db_name = "week_%s.db" % now.strftime("%V")
@ -48,10 +55,10 @@ def db_init(db_name=None):
"timestamp INTEGER, " + "timestamp INTEGER, " +
"event TEXT, " + "event TEXT, " +
"FOREIGN KEY(station_id) REFERENCES stations(id) ON DELETE CASCADE)") "FOREIGN KEY(station_id) REFERENCES stations(id) ON DELETE CASCADE)")
c.execute("CREATE INDEX IF NOT EXISTS stationstats_station_id ON stationsstats (station_id)"); c.execute("CREATE INDEX IF NOT EXISTS stationstats_station_id ON stationsstats (station_id)")
c.execute("CREATE INDEX IF NOT EXISTS stationsstats_updated ON stationsstats (updated)"); c.execute("CREATE INDEX IF NOT EXISTS stationsstats_updated ON stationsstats (updated)")
c.execute("CREATE INDEX IF NOT EXISTS stationsevents_station_id ON stationsevents (station_id)"); c.execute("CREATE INDEX IF NOT EXISTS stationsevents_station_id ON stationsevents (station_id)")
c.execute("CREATE INDEX IF NOT EXISTS stationsevents_timestamp ON stationsevents (timestamp)"); c.execute("CREATE INDEX IF NOT EXISTS stationsevents_timestamp ON stationsevents (timestamp)")
conn.commit() conn.commit()
return conn return conn
@ -62,17 +69,35 @@ def update_stations(conn):
:param conn: Database connection. :param conn: Database connection.
""" """
logging.info('Get all stations from database...')
c = conn.cursor() c = conn.cursor()
database_stations = {i[0]: i database_stations = {
for i in i[0]: i
c.execute("SELECT id, name, address, latitude, longitude, banking, bonus, bike_stands FROM stations").fetchall()} for i in c.execute(
"SELECT id, name, address, latitude, longitude, banking, bonus, bike_stands FROM stations"
).fetchall()
}
logging.info('Get updated Velib stations from the API...')
velib = pybikes.get("velib") velib = pybikes.get("velib")
velib.update() velib.update()
for station in velib.stations: fetched_stations = {
station.extra['uid']: station
for station in velib.stations
if 'uid' in station.extra
}
# List of SQL queries to perform for
events = [] # events happening on stations (temporary closure etc)
stations_update = [] # Update of stations (such as new stands number)
new_stations = [] # New stations to add to the list
stats = [] # Current stats of the station
logging.info('Processing fetched stations...')
for uid, station in fetched_stations.items():
try: try:
# Get old station entry if it exists old_station = database_stations[uid]
old_station = database_stations[station.extra["uid"]]
# Diff the two stations # Diff the two stations
event = [] event = []
if station.name != old_station[1]: if station.name != old_station[1]:
@ -87,60 +112,86 @@ def update_stations(conn):
event.append({"key": "longitude", event.append({"key": "longitude",
"old_value": old_station[4], "old_value": old_station[4],
"new_value": station.longitude}) "new_value": station.longitude})
if station.extra["banking"] != old_station[5]: if (
"banking" in station.extra
and station.extra["banking"] != old_station[5]
):
event.append({"key": "banking", event.append({"key": "banking",
"old_value": old_station[5], "old_value": old_station[5],
"new_value": station.extra["banking"]}) "new_value": station.extra["banking"]})
if station.extra["slots"] != old_station[7]: if (
"slots" in station.extra
and station.extra["slots"] != old_station[7]
):
event.append({"key": "bike_stands", event.append({"key": "bike_stands",
"old_value": old_station[7], "old_value": old_station[7],
"new_value": station.extra["slots"]}) "new_value": station.extra["slots"]})
# If diff was found # If diff was found
if len(event) > 0: if len(event) > 0:
# Update stations_update.append(
c.execute("UPDATE " + (station.name,
"stations " + station.latitude,
"SET name=?, latitude=?, longitude=?, " + station.longitude,
"banking=?, bike_stands=? WHERE id=?", station.extra["banking"],
(station.name, station.extra["slots"],
station.latitude, uid)
station.longitude, )
station.extra["banking"], events.append(
station.extra["slots"], (uid, int(time.time()), json.dumps(event))
station.extra["uid"])) )
# And insert event in the table
c.execute("INSERT INTO " +
"stationsevents(station_id, timestamp, event) " +
"VALUES(?, ?, ?)",
(station.extra["uid"],
int(time.time()),
json.dumps(event)))
except KeyError: except KeyError:
c.execute("INSERT INTO " + # Add the station to the database
"stations(id, name, address, latitude, longitude, banking, bonus, bike_stands) " + new_stations.append(
"VALUES(?, ?, ?, ?, ?, ?, ?, ?)", (uid,
(station.extra["uid"], station.name,
station.name, "", # Not available
"", # Not available station.latitude,
station.latitude, station.longitude,
station.longitude, station.extra["banking"],
station.extra["banking"], False, # Not available
False, # Not available station.extra["slots"])
station.extra["slots"])) )
except TypeError: stats.append(
conn.rollback() (uid,
return station.bikes - station.extra["ebikes"],
station.extra["ebikes"],
station.free,
station.extra["status"],
int(time.time())) # Not available, using current timestamp
)
c.execute("INSERT INTO " + # Update stations
"stationsstats(station_id, available_bikes, available_ebikes, free_stands, status, updated) " + logging.info('Updating stations in db...')
"VALUES(?, ?, ?, ?, ?, ?)", c.executemany(
(station.extra["uid"], "UPDATE stations SET name=?, latitude=?, longitude=?, " +
station.bikes - station.extra["ebikes"], "banking=?, bike_stands=? WHERE id=?",
station.extra["ebikes"], stations_update
station.free, )
station.extra["status"], # Insert events in the table
int(time.time()))) # Not available, using current timestamp logging.info('Storing stations events in db...')
conn.commit() c.executemany(
"INSERT INTO stationsevents(station_id, timestamp, event) " +
"VALUES(?, ?, ?)",
events
)
# Add the station to the database
logging.info('Storing new stations in db...')
c.executemany(
"INSERT INTO " +
"stations(id, name, address, latitude, longitude, banking, bonus, bike_stands) " +
"VALUES(?, ?, ?, ?, ?, ?, ?, ?)",
new_stations
)
# Insert the current state in the db
logging.info('Storing current stations stats in db...')
c.executemany(
"INSERT INTO " +
"stationsstats(station_id, available_bikes, available_ebikes, free_stands, status, updated) " +
"VALUES(?, ?, ?, ?, ?, ?)",
stats
)
conn.commit()
def main(): def main():