start the transition to sqlite3 for storage
This commit is contained in:
parent
fe02b11951
commit
bba899677f
8 changed files with 326 additions and 51 deletions
4
db/__init__.py
Normal file
4
db/__init__.py
Normal file
|
@ -0,0 +1,4 @@
|
|||
from db.migration import migrate_db
|
||||
from db.conn import create_conn
|
||||
|
||||
__all__ = ["migrate_db", "create_conn"]
|
8
db/conn.py
Normal file
8
db/conn.py
Normal file
|
@ -0,0 +1,8 @@
|
|||
import sqlite3
|
||||
|
||||
|
||||
def create_conn(db_path: str) -> sqlite3.Connection:
|
||||
db_conn = sqlite3.connect(db_path)
|
||||
db_conn.execute("PRAGMA foreign_keys = ON")
|
||||
|
||||
return db_conn
|
0
db/message.py
Normal file
0
db/message.py
Normal file
64
db/migration.py
Normal file
64
db/migration.py
Normal file
|
@ -0,0 +1,64 @@
|
|||
import logging
|
||||
import sqlite3
|
||||
|
||||
__STEPS = [
|
||||
"""
|
||||
BEGIN;
|
||||
|
||||
CREATE TABLE "transaction" (
|
||||
id INTEGER PRIMARY KEY NOT NULL CHECK (typeof(id) = 'integer'),
|
||||
email_message_id TEXT NOT NULL CHECK (typeof(email_message_id) = 'text'),
|
||||
amount TEXT NOT NULL CHECK (typeof(amount) = 'text'),
|
||||
card_ending_in TEXT NOT NULL CHECK (typeof(card_ending_in) = 'text'),
|
||||
merchant TEXT NOT NULL CHECK (typeof(merchant) = 'text'),
|
||||
date TEXT NOT NULL CHECK (typeof(date) = 'text'),
|
||||
time TEXT NOT NULL CHECK (typeof(time) = 'text'),
|
||||
acknowledged BOOLEAN NOT NULL CHECK (typeof(acknowledged) = 'integer'),
|
||||
ts_update INTEGER NOT NULL CHECK (typeof(ts_update) = 'integer'),
|
||||
ts_insert INTEGER NOT NULL CHECK (typeof(ts_insert) = 'integer')
|
||||
);
|
||||
CREATE UNIQUE INDEX ix__transaction__email_message_id ON
|
||||
"transaction" (email_message_id);
|
||||
CREATE INDEX ix__transaction__acknowledged ON
|
||||
"transaction" (acknowledged);
|
||||
|
||||
CREATE TABLE notification (
|
||||
id INTEGER PRIMARY KEY NOT NULL CHECK (typeof(id) = 'integer'),
|
||||
id_transaction INTEGER NOT NULL CHECK (typeof(id_transaction) = 'integer'),
|
||||
pushover_receipt TEXT NOT NULL CHECK (typeof(pushover_receipt) = 'text'),
|
||||
acknowledged BOOLEAN NOT NULL CHECK (typeof(acknowledged) = 'integer'),
|
||||
expired BOOLEAN NOT NULL CHECK (typeof(expired) = 'integer'),
|
||||
ts_update INTEGER NOT NULL CHECK (typeof(ts_update) = 'integer'),
|
||||
ts_insert INTEGER NOT NULL CHECK (typeof(ts_insert) = 'integer'),
|
||||
FOREIGN KEY (id_transaction) REFERENCES "transaction" (id)
|
||||
);
|
||||
CREATE INDEX ix__notification__id_transaction ON
|
||||
notification (id_transaction);
|
||||
|
||||
CREATE TABLE schema_version (
|
||||
id INTEGER PRIMARY KEY NOT NULL CHECK (typeof(id) = 'integer'),
|
||||
ts_insert INTEGER NOT NULL CHECK (typeof(ts_insert) = 'integer')
|
||||
);
|
||||
|
||||
INSERT INTO schema_version (id, ts_insert) VALUES (1, strftime('%s'));
|
||||
|
||||
COMMIT;
|
||||
"""
|
||||
]
|
||||
|
||||
|
||||
def migrate_db(log: logging.Logger, db_conn: sqlite3.Connection) -> None:
|
||||
schema_verison = 0
|
||||
try:
|
||||
log.info("checking latest schema_version")
|
||||
result = db_conn.execute("SELECT MAX(id) FROM schema_version").fetchone()
|
||||
if result is not None:
|
||||
schema_verison = result[0]
|
||||
log.info(f"schema version is {schema_verison}")
|
||||
except Exception:
|
||||
log.info(f"missing schema_version table, assuming {schema_verison}")
|
||||
|
||||
for step_number, step in enumerate(__STEPS[schema_verison:], start=1):
|
||||
log.info(f"applying schema_version {step_number}")
|
||||
db_conn.executescript(step)
|
||||
log.info(f"successfully applied schema_version {step_number}")
|
65
db/notification.py
Normal file
65
db/notification.py
Normal file
|
@ -0,0 +1,65 @@
|
|||
from dataclasses import dataclass
|
||||
from datetime import datetime
|
||||
import logging
|
||||
import sqlite3
|
||||
|
||||
from db import conn
|
||||
|
||||
|
||||
@dataclass(frozen=True)
|
||||
class Notification:
|
||||
id: int
|
||||
id_transaction: int
|
||||
pushover_receipt: str
|
||||
acknowledged: bool
|
||||
expired: bool
|
||||
ts_update: datetime
|
||||
ts_insert: datetime
|
||||
|
||||
|
||||
class NotificationManager:
|
||||
def __init__(self, log: logging.Logger, db_conn: sqlite3.Connection):
|
||||
self.__log = log
|
||||
self.__db_conn = db_conn
|
||||
|
||||
def insert_notification(self, notification: Notification) -> Notification:
|
||||
now = datetime.now()
|
||||
result = self.__db_conn.execute(
|
||||
"""
|
||||
INSERT INTO notification (
|
||||
id_transaction,
|
||||
pushover_receipt,
|
||||
acknowledged,
|
||||
expired,
|
||||
ts_update,
|
||||
ts_insert
|
||||
) VALUES (
|
||||
?,
|
||||
?,
|
||||
?,
|
||||
?,
|
||||
?,
|
||||
?
|
||||
) RETURNING id;
|
||||
""",
|
||||
(
|
||||
notification.id_transaction,
|
||||
notification.pushover_receipt,
|
||||
notification.acknowledged,
|
||||
notification.expired,
|
||||
now.strftime("%s"),
|
||||
now.strftime("%s"),
|
||||
),
|
||||
).fetchone()
|
||||
|
||||
self.__db_conn.commit()
|
||||
|
||||
return Notification(
|
||||
id=result[0],
|
||||
id_transaction=notification.id_transaction,
|
||||
pushover_receipt=notification.pushover_receipt,
|
||||
acknowledged=notification.acknowledged,
|
||||
expired=notification.expired,
|
||||
ts_update=now,
|
||||
ts_insert=now,
|
||||
)
|
115
db/transaction.py
Normal file
115
db/transaction.py
Normal file
|
@ -0,0 +1,115 @@
|
|||
from datetime import datetime
|
||||
import logging
|
||||
import sqlite3
|
||||
from typing import Iterable, Optional
|
||||
from dataclasses import dataclass
|
||||
|
||||
|
||||
@dataclass(frozen=True)
|
||||
class Transaction:
|
||||
id: int
|
||||
email_message_id: str
|
||||
amount: str
|
||||
card_ending_in: str
|
||||
merchant: str
|
||||
date: str
|
||||
time: str
|
||||
acknowledged: bool
|
||||
ts_update: datetime
|
||||
ts_insert: datetime
|
||||
|
||||
|
||||
class TransactionManager:
|
||||
def __init__(self, log: logging.Logger, db_conn: sqlite3.Connection):
|
||||
self.__log = log
|
||||
self.__db_conn = db_conn
|
||||
|
||||
def get_by_email_message_id(self, email_message_id: str) -> Optional[Transaction]:
|
||||
result = self.__db_conn.execute(
|
||||
"""
|
||||
SELECT
|
||||
id,
|
||||
email_message_id,
|
||||
amount,
|
||||
card_ending_in,
|
||||
merchant,
|
||||
date,
|
||||
time,
|
||||
acknowledged,
|
||||
ts_update,
|
||||
ts_insert
|
||||
FROM "transaction"
|
||||
WHERE email_message_id = ?
|
||||
""",
|
||||
(email_message_id,),
|
||||
).fetchone()
|
||||
|
||||
if result is None:
|
||||
return None
|
||||
|
||||
return Transaction(
|
||||
id=result[0],
|
||||
email_message_id=result[1],
|
||||
amount=result[2],
|
||||
card_ending_in=result[3],
|
||||
merchant=result[4],
|
||||
date=result[5],
|
||||
time=result[6],
|
||||
acknowledged=result[7],
|
||||
ts_update=result[8],
|
||||
ts_insert=result[9],
|
||||
)
|
||||
|
||||
def insert_transaction(self, transaction: Transaction) -> Transaction:
|
||||
now = datetime.now()
|
||||
result = self.__db_conn.execute(
|
||||
"""
|
||||
INSERT INTO "transaction" (
|
||||
email_message_id,
|
||||
amount,
|
||||
card_ending_in,
|
||||
merchant,
|
||||
date,
|
||||
time,
|
||||
acknowledged,
|
||||
ts_update,
|
||||
ts_insert
|
||||
) VALUES (
|
||||
?,
|
||||
?,
|
||||
?,
|
||||
?,
|
||||
?,
|
||||
?,
|
||||
?,
|
||||
?,
|
||||
?
|
||||
) RETURNING id
|
||||
""",
|
||||
(
|
||||
transaction.email_message_id,
|
||||
transaction.amount,
|
||||
transaction.card_ending_in,
|
||||
transaction.merchant,
|
||||
transaction.date,
|
||||
transaction.time,
|
||||
transaction.acknowledged,
|
||||
int(now.strftime("%s")),
|
||||
int(now.strftime("%s")),
|
||||
),
|
||||
).fetchone()
|
||||
|
||||
self.__db_conn.commit()
|
||||
|
||||
return Transaction(
|
||||
id=result[0],
|
||||
email_message_id=transaction.email_message_id,
|
||||
amount=transaction.amount,
|
||||
card_ending_in=transaction.card_ending_in,
|
||||
merchant=transaction.merchant,
|
||||
date=transaction.date,
|
||||
time=transaction.time,
|
||||
acknowledged=transaction.acknowledged,
|
||||
ts_update=now,
|
||||
ts_insert=now,
|
||||
)
|
Loading…
Add table
Add a link
Reference in a new issue