Database schema migration to version 3.
This commit is contained in:
parent
a4ed09933e
commit
0adba41c8d
7 changed files with 170 additions and 8 deletions
|
@ -5,7 +5,7 @@ from typing import List, Optional, Any, Type
|
|||
import crypt
|
||||
from hmac import compare_digest
|
||||
|
||||
from matemat.db.primitives import User, Product
|
||||
from matemat.db.primitives import User, Product, ReceiptPreference
|
||||
from matemat.exceptions import AuthenticationError, DatabaseConsistencyError
|
||||
from matemat.db import DatabaseWrapper
|
||||
from matemat.db.wrapper import Transaction
|
||||
|
@ -101,14 +101,18 @@ class MatematDatabase(object):
|
|||
"""
|
||||
with self.db.transaction(exclusive=False) as c:
|
||||
# Fetch all values to construct the user
|
||||
c.execute('SELECT user_id, username, email, is_admin, is_member, balance FROM users WHERE user_id = ?',
|
||||
c.execute('''
|
||||
SELECT user_id, username, email, is_admin, is_member, balance, receipt_pref
|
||||
FROM users
|
||||
WHERE user_id = ?
|
||||
''',
|
||||
[uid])
|
||||
row = c.fetchone()
|
||||
if row is None:
|
||||
raise ValueError(f'No user with user ID {uid} exists.')
|
||||
# Unpack the row and construct the user
|
||||
user_id, username, email, is_admin, is_member, balance = row
|
||||
return User(user_id, username, balance, email, is_admin, is_member)
|
||||
user_id, username, email, is_admin, is_member, balance, receipt_pref = row
|
||||
return User(user_id, username, balance, email, is_admin, is_member, ReceiptPreference(receipt_pref))
|
||||
|
||||
def create_user(self,
|
||||
username: str,
|
||||
|
@ -261,6 +265,7 @@ class MatematDatabase(object):
|
|||
balance: int = kwargs['balance'] if 'balance' in kwargs else user.balance
|
||||
is_admin: bool = kwargs['is_admin'] if 'is_admin' in kwargs else user.is_admin
|
||||
is_member: bool = kwargs['is_member'] if 'is_member' in kwargs else user.is_member
|
||||
receipt_pref: ReceiptPreference = kwargs['receipt_pref'] if 'receipt_pref' in kwargs else user.receipt_pref
|
||||
with self.db.transaction() as c:
|
||||
c.execute('SELECT balance FROM users WHERE user_id = :user_id', {'user_id': user.id})
|
||||
row = c.fetchone()
|
||||
|
@ -290,6 +295,7 @@ class MatematDatabase(object):
|
|||
balance = :balance,
|
||||
is_admin = :is_admin,
|
||||
is_member = :is_member,
|
||||
receipt_pref = :receipt_pref,
|
||||
lastchange = STRFTIME('%s', 'now')
|
||||
WHERE user_id = :user_id
|
||||
''', {
|
||||
|
@ -298,7 +304,8 @@ class MatematDatabase(object):
|
|||
'email': email,
|
||||
'balance': balance,
|
||||
'is_admin': is_admin,
|
||||
'is_member': is_member
|
||||
'is_member': is_member,
|
||||
'receipt_pref': receipt_pref.value
|
||||
})
|
||||
# Only update the actual user object after the changes in the database succeeded
|
||||
user.name = name
|
||||
|
@ -306,6 +313,7 @@ class MatematDatabase(object):
|
|||
user.balance = balance
|
||||
user.is_admin = is_admin
|
||||
user.is_member = is_member
|
||||
user.receipt_pref = receipt_pref
|
||||
|
||||
def delete_user(self, user: User) -> None:
|
||||
"""
|
||||
|
|
|
@ -113,3 +113,46 @@ def migrate_schema_1_to_2(c: sqlite3.Cursor):
|
|||
ta_id -= 1
|
||||
# Drop the old consumption table
|
||||
c.execute('DROP TABLE consumption')
|
||||
|
||||
|
||||
def migrate_schema_2_to_3(c: sqlite3.Cursor):
|
||||
# Add missing column to users table
|
||||
c.execute('ALTER TABLE users ADD COLUMN receipt_pref INTEGER(1) NOT NULL DEFAULT 0')
|
||||
|
||||
# Change modifications table
|
||||
c.execute('''
|
||||
CREATE TABLE modifications_new (
|
||||
ta_id INTEGER NOT NULL,
|
||||
agent TEXT NOT NULL,
|
||||
reason TEXT DEFAULT NULL,
|
||||
PRIMARY KEY (ta_id),
|
||||
FOREIGN KEY (ta_id) REFERENCES transactions(ta_id)
|
||||
ON DELETE CASCADE ON UPDATE CASCADE
|
||||
)
|
||||
''')
|
||||
c.execute('''
|
||||
INSERT INTO modifications_new (ta_id, agent, reason)
|
||||
SELECT m.ta_id, COALESCE(u.username, '<unknown>'), m.reason
|
||||
FROM modifications as m
|
||||
LEFT JOIN users as u
|
||||
ON u.user_id = m.agent_id
|
||||
''')
|
||||
c.execute('DROP TABLE modifications')
|
||||
c.execute('ALTER TABLE modifications_new RENAME TO modifications')
|
||||
|
||||
# Create missing table
|
||||
c.execute('''
|
||||
CREATE TABLE receipts ( -- receipts sent to the users
|
||||
receipt_id INTEGER PRIMARY KEY,
|
||||
user_id INTEGER NOT NULL,
|
||||
first_ta_id INTEGER NOT NULL,
|
||||
last_ta_id INTEGER NOT NULL,
|
||||
date INTEGER(8) DEFAULT (STRFTIME('%s', 'now')),
|
||||
FOREIGN KEY (user_id) REFERENCES users(user_id)
|
||||
ON DELETE CASCADE ON UPDATE CASCADE,
|
||||
FOREIGN KEY (first_ta_id) REFERENCES transactions(ta_id)
|
||||
ON DELETE SET NULL ON UPDATE CASCADE,
|
||||
FOREIGN KEY (last_ta_id) REFERENCES transactions(ta_id)
|
||||
ON DELETE SET NULL ON UPDATE CASCADE
|
||||
)
|
||||
''')
|
||||
|
|
27
matemat/db/primitives/ReceiptPreference.py
Normal file
27
matemat/db/primitives/ReceiptPreference.py
Normal file
|
@ -0,0 +1,27 @@
|
|||
from enum import Enum
|
||||
|
||||
|
||||
class ReceiptPreference(Enum):
|
||||
"""
|
||||
A user's preference for the frequency of receiving receipts.
|
||||
"""
|
||||
|
||||
"""
|
||||
No receipts should be generated.
|
||||
"""
|
||||
NONE = 0
|
||||
|
||||
"""
|
||||
A receipt should be generated for each transaction.
|
||||
"""
|
||||
EACH = 1
|
||||
|
||||
"""
|
||||
A receipt should be generated once a month.
|
||||
"""
|
||||
MONTHLY = 2
|
||||
|
||||
"""
|
||||
A receipt should be generated once a year.
|
||||
"""
|
||||
YEARLY = 3
|
|
@ -2,6 +2,7 @@
|
|||
from typing import Optional
|
||||
|
||||
from dataclasses import dataclass
|
||||
from matemat.db.primitives.ReceiptPreference import ReceiptPreference
|
||||
|
||||
|
||||
@dataclass
|
||||
|
@ -17,6 +18,7 @@ class User:
|
|||
:param email: The user's e-mail address (optional).
|
||||
:param admin: Whether the user is an administrator.
|
||||
:param member: Whether the user is a member.
|
||||
:param receipt_pref: The user's preference on how often to receive transaction receipts.
|
||||
"""
|
||||
|
||||
id: int
|
||||
|
@ -25,3 +27,4 @@ class User:
|
|||
email: Optional[str] = None
|
||||
is_admin: bool = False
|
||||
is_member: bool = False
|
||||
receipt_pref: ReceiptPreference = ReceiptPreference.NONE
|
||||
|
|
|
@ -4,3 +4,4 @@ This package provides the 'primitive types' the Matemat software deals with - na
|
|||
|
||||
from .User import User
|
||||
from .Product import Product
|
||||
from .ReceiptPreference import ReceiptPreference
|
||||
|
|
|
@ -101,3 +101,81 @@ SCHEMAS[2] = [
|
|||
ON DELETE CASCADE ON UPDATE CASCADE
|
||||
);
|
||||
''']
|
||||
|
||||
SCHEMAS[3] = [
|
||||
'''
|
||||
CREATE TABLE users (
|
||||
user_id INTEGER PRIMARY KEY,
|
||||
username TEXT UNIQUE NOT NULL,
|
||||
email TEXT DEFAULT NULL,
|
||||
password TEXT NOT NULL,
|
||||
touchkey TEXT DEFAULT NULL,
|
||||
is_admin INTEGER(1) NOT NULL DEFAULT 0,
|
||||
is_member INTEGER(1) NOT NULL DEFAULT 1,
|
||||
balance INTEGER(8) NOT NULL DEFAULT 0,
|
||||
lastchange INTEGER(8) NOT NULL DEFAULT 0,
|
||||
receipt_pref INTEGER(1) NOT NULL DEFAULT 0
|
||||
);
|
||||
''',
|
||||
'''
|
||||
CREATE TABLE products (
|
||||
product_id INTEGER PRIMARY KEY,
|
||||
name TEXT UNIQUE NOT NULL,
|
||||
stock INTEGER(8) NOT NULL DEFAULT 0,
|
||||
price_member INTEGER(8) NOT NULL,
|
||||
price_non_member INTEGER(8) NOT NULL
|
||||
);
|
||||
''',
|
||||
'''
|
||||
CREATE TABLE transactions ( -- "superclass" of the following 3 tables
|
||||
ta_id INTEGER PRIMARY KEY,
|
||||
user_id INTEGER NOT NULL,
|
||||
value INTEGER(8) NOT NULL,
|
||||
old_balance INTEGER(8) NOT NULL,
|
||||
date INTEGER(8) DEFAULT (STRFTIME('%s', 'now')),
|
||||
FOREIGN KEY (user_id) REFERENCES users(user_id)
|
||||
ON DELETE CASCADE ON UPDATE CASCADE
|
||||
);
|
||||
''',
|
||||
'''
|
||||
CREATE TABLE consumptions ( -- transactions involving buying a product
|
||||
ta_id INTEGER PRIMARY KEY,
|
||||
product_id INTEGER DEFAULT NULL,
|
||||
FOREIGN KEY (ta_id) REFERENCES transactions(ta_id)
|
||||
ON DELETE CASCADE ON UPDATE CASCADE,
|
||||
FOREIGN KEY (product_id) REFERENCES products(product_id)
|
||||
ON DELETE SET NULL ON UPDATE CASCADE
|
||||
);
|
||||
''',
|
||||
'''
|
||||
CREATE TABLE deposits ( -- transactions involving depositing cash
|
||||
ta_id INTEGER PRIMARY KEY,
|
||||
FOREIGN KEY (ta_id) REFERENCES transactions(ta_id)
|
||||
ON DELETE CASCADE ON UPDATE CASCADE
|
||||
);
|
||||
''',
|
||||
'''
|
||||
CREATE TABLE modifications ( -- transactions involving balance modification by an admin
|
||||
ta_id INTEGER NOT NULL,
|
||||
agent TEXT NOT NULL,
|
||||
reason TEXT DEFAULT NULL,
|
||||
PRIMARY KEY (ta_id),
|
||||
FOREIGN KEY (ta_id) REFERENCES transactions(ta_id)
|
||||
ON DELETE CASCADE ON UPDATE CASCADE
|
||||
);
|
||||
''',
|
||||
'''
|
||||
CREATE TABLE receipts ( -- receipts sent to the users
|
||||
receipt_id INTEGER PRIMARY KEY,
|
||||
user_id INTEGER NOT NULL,
|
||||
first_ta_id INTEGER NOT NULL,
|
||||
last_ta_id INTEGER NOT NULL,
|
||||
date INTEGER(8) DEFAULT (STRFTIME('%s', 'now')),
|
||||
FOREIGN KEY (user_id) REFERENCES users(user_id)
|
||||
ON DELETE CASCADE ON UPDATE CASCADE,
|
||||
FOREIGN KEY (first_ta_id) REFERENCES transactions(ta_id)
|
||||
ON DELETE SET NULL ON UPDATE CASCADE,
|
||||
FOREIGN KEY (last_ta_id) REFERENCES transactions(ta_id)
|
||||
ON DELETE SET NULL ON UPDATE CASCADE
|
||||
);
|
||||
''']
|
||||
|
|
|
@ -6,7 +6,7 @@ import sqlite3
|
|||
|
||||
from matemat.exceptions import DatabaseConsistencyError
|
||||
from matemat.db.schemas import SCHEMAS
|
||||
from matemat.db.migrations import migrate_schema_1_to_2
|
||||
from matemat.db.migrations import migrate_schema_1_to_2, migrate_schema_2_to_3
|
||||
|
||||
|
||||
class Transaction(object):
|
||||
|
@ -43,7 +43,7 @@ class Transaction(object):
|
|||
|
||||
class DatabaseWrapper(object):
|
||||
|
||||
SCHEMA_VERSION = 2
|
||||
SCHEMA_VERSION = 3
|
||||
|
||||
def __init__(self, filename: str) -> None:
|
||||
self._filename: str = filename
|
||||
|
@ -77,8 +77,10 @@ class DatabaseWrapper(object):
|
|||
def _upgrade(self, from_version: int, to_version: int) -> None:
|
||||
with self.transaction() as c:
|
||||
# Note to future s3lph: If there are further migrations, also consider upgrades like 1 -> 3
|
||||
if from_version == 1 and to_version == 2:
|
||||
if from_version == 1 and to_version >= 2:
|
||||
migrate_schema_1_to_2(c)
|
||||
if from_version <= 2 and to_version >= 3:
|
||||
migrate_schema_2_to_3(c)
|
||||
|
||||
def connect(self) -> None:
|
||||
if self.is_connected():
|
||||
|
|
Loading…
Reference in a new issue