import sqlite3 UPSTREAM_BASE_URL = "https://api.tfl.gov.uk" DB_NAME = "bike-data.db" def get_db_connection(): conn = sqlite3.connect(DB_NAME, timeout=300) conn.row_factory = sqlite3.Row return conn # ACCIDENTS def get_all_accidents(): query = """SELECT id, lat, lon, location, date, severity FROM accidents""" return get_db_connection().execute(query).fetchall() def get_accidents(year: str): query = """ SELECT id, lat, lon, location, date, severity FROM accidents WHERE STRFTIME('%Y', date) = ?""" return get_db_connection().execute(query, (year,)).fetchall() # DASHBOARD def get_dashboard(station_id): query = """ SELECT b.id_num as id, b.common_name AS commonName, b.lat, b.lon, d.max_end_date AS maxEndDate, d.max_start_date AS maxStartDate FROM usage_stats u JOIN bike_points b ON u.start_station_id = b.id_num JOIN dashboard d ON u.start_station_id = d.id WHERE u.start_station_id = ?""" return get_db_connection().execute(query, (station_id,)).fetchone() def get_dashboard_to(station_id, start_date, end_date): query = """ SELECT topPoints.*, b.lat AS stationLat, b.lon AS stationLon FROM ( SELECT u.end_station_name AS stationName, u.end_station_id AS stationId, count(*) AS number, round(avg(u.duration)) AS avgDuration FROM usage_stats u WHERE u.start_station_id = ? AND date(u.start_date, 'unixepoch') BETWEEN ? AND ? GROUP BY u.end_station_name ORDER BY number DESC LIMIT 3 ) as topPoints JOIN bike_points b ON b.id_num = topPoints.stationId""" return get_db_connection().execute(query, (station_id, start_date, end_date)).fetchall() def get_dashboard_from(station_id, start_date, end_date): query = """ SELECT topPoints.*, b.lat AS stationLat, b.lon AS stationLon FROM ( SELECT u.start_station_name AS stationName, u.start_station_id AS stationId, count(*) AS number, round(avg(u.duration)) AS avgDuration FROM usage_stats u WHERE u.end_station_id = ? AND date(u.start_date, 'unixepoch') BETWEEN ? AND ? GROUP BY u.start_station_name ORDER BY number DESC LIMIT 3 ) as topPoints JOIN bike_points b ON b.id_num = topPoints.stationId""" return get_db_connection().execute(query, (station_id, start_date, end_date)).fetchall() def get_dashboard_duration(station_id, start_date, end_date): query = """ SELECT count(*) AS number, CASE WHEN duration <= 300 THEN '0-5' WHEN duration <= 900 THEN '5-15' WHEN duration <= 1800 THEN '15-30' WHEN duration <= 2700 THEN '30-45' ELSE '45+' END AS minutesGroup FROM usage_stats WHERE start_station_id = ? AND date(start_date, 'unixepoch') BETWEEN ? AND ? GROUP BY minutesGroup""" return get_db_connection().execute(query, (station_id, start_date, end_date)).fetchall() def get_dashboard_time(station_id, start_date, end_date): query = """ SELECT substr(strftime('%H:%M', start_date, 'unixepoch'), 1, 4) || '0' as timeFrame, count(*) AS number, round(avg(duration)) AS avgDuration FROM usage_stats WHERE start_station_id = ? AND date(start_date, 'unixepoch') BETWEEN ? AND ? GROUP BY substr(strftime('%H:%M', start_date, 'unixepoch'), 1, 4)""" return get_db_connection().execute(query, (station_id, start_date, end_date)).fetchall()