Yet another schema change: consumptions now contains the product name rather than the product id.

This commit is contained in:
s3lph 2018-09-01 02:54:55 +02:00
parent fec9c3d7ac
commit ff0c13d367
4 changed files with 41 additions and 11 deletions

View file

@ -472,10 +472,10 @@ class MatematDatabase(object):
'old_balance': user.balance 'old_balance': user.balance
}) })
c.execute(''' c.execute('''
INSERT INTO consumptions (ta_id, product_id) INSERT INTO consumptions (ta_id, product)
VALUES (last_insert_rowid(), :product_id) VALUES (last_insert_rowid(), :product)
''', { ''', {
'product_id': product.id 'product': product.name
}) })
# Subtract the price from the user's account balance. # Subtract the price from the user's account balance.
c.execute(''' c.execute('''

View file

@ -135,6 +135,25 @@ def migrate_schema_2_to_3(c: sqlite3.Cursor):
c.execute('DROP TABLE transactions') c.execute('DROP TABLE transactions')
c.execute('ALTER TABLE transactions_new RENAME TO transactions') c.execute('ALTER TABLE transactions_new RENAME TO transactions')
# Change consumptions table
c.execute('''
CREATE TABLE consumptions_new (
ta_id INTEGER PRIMARY KEY,
product TEXT NOT NULL,
FOREIGN KEY (ta_id) REFERENCES transactions(ta_id)
ON DELETE CASCADE ON UPDATE CASCADE
)
''')
c.execute('''
INSERT INTO consumptions_new (ta_id, product)
SELECT c.ta_id, COALESCE(p.name, '<unknown>')
FROM consumptions as c
LEFT JOIN products as p
ON c.product_id = p.product_id
''')
c.execute('DROP TABLE consumptions')
c.execute('ALTER TABLE consumptions_new RENAME TO consumptions')
# Change modifications table # Change modifications table
c.execute(''' c.execute('''
CREATE TABLE modifications_new ( CREATE TABLE modifications_new (

View file

@ -140,11 +140,9 @@ SCHEMAS[3] = [
''' '''
CREATE TABLE consumptions ( -- transactions involving buying a product CREATE TABLE consumptions ( -- transactions involving buying a product
ta_id INTEGER PRIMARY KEY, ta_id INTEGER PRIMARY KEY,
product_id INTEGER DEFAULT NULL, product TEXT NOT NULL,
FOREIGN KEY (ta_id) REFERENCES transactions(ta_id) FOREIGN KEY (ta_id) REFERENCES transactions(ta_id)
ON DELETE CASCADE ON UPDATE CASCADE, ON DELETE CASCADE ON UPDATE CASCADE
FOREIGN KEY (product_id) REFERENCES products(product_id)
ON DELETE SET NULL ON UPDATE CASCADE
); );
''', ''',
''' '''

View file

@ -52,7 +52,10 @@ class TestMigrations(unittest.TestCase):
cursor.execute('PRAGMA user_version = 1') cursor.execute('PRAGMA user_version = 1')
# Kick off the migration # Kick off the migration
schema_version = self.db.SCHEMA_VERSION
self.db.SCHEMA_VERSION = 2
self.db._setup() self.db._setup()
self.db.SCHEMA_VERSION = schema_version
# Test whether the new tables were created # Test whether the new tables were created
cursor.execute('PRAGMA table_info(transactions)') cursor.execute('PRAGMA table_info(transactions)')
@ -136,25 +139,29 @@ class TestMigrations(unittest.TestCase):
cursor.execute(''' cursor.execute('''
INSERT INTO products VALUES INSERT INTO products VALUES
(1, 'Club Mate', 42, 200, 250), (1, 'Club Mate', 42, 200, 250),
(2, 'Flora Power Mate (1/4l)', 10, 100, 150) (2, 'Flora Power Mate', 10, 100, 150)
''') ''')
cursor.execute(''' cursor.execute('''
INSERT INTO transactions VALUES INSERT INTO transactions VALUES
(1, 1, 4200, 0, 1000), -- deposit (1, 1, 4200, 0, 1000), -- deposit
(2, 2, 1337, 0, 1001), -- modification (2, 2, 1337, 0, 1001), -- modification
(3, 3, 1337, 0, 1001), -- modification with deleted agent (3, 3, 1337, 0, 1002), -- modification with deleted agent
(4, 2, 200, 1337, 1002) -- consumption (4, 2, -200, 1337, 1003), -- consumption
(5, 3, -200, 1337, 1004) -- consumption with deleted product
''') ''')
cursor.execute('''INSERT INTO deposits VALUES (1)''') cursor.execute('''INSERT INTO deposits VALUES (1)''')
cursor.execute(''' cursor.execute('''
INSERT INTO modifications VALUES INSERT INTO modifications VALUES
(2, 1, 'Account migration'), (2, 1, 'Account migration'),
(3, 42, 'You can''t find out who i am... MUAHAHAHA!!!')''') (3, 42, 'You can''t find out who i am... MUAHAHAHA!!!')''')
cursor.execute('''INSERT INTO consumptions VALUES (4, 2)''') cursor.execute('''INSERT INTO consumptions VALUES (4, 2), (5, 42)''')
cursor.execute('''PRAGMA user_version = 2''') cursor.execute('''PRAGMA user_version = 2''')
# Kick off the migration # Kick off the migration
schema_version = self.db.SCHEMA_VERSION
self.db.SCHEMA_VERSION = 3
self.db._setup() self.db._setup()
self.db.SCHEMA_VERSION = schema_version
# Make sure the receipts table was created # Make sure the receipts table was created
cursor.execute('''SELECT COUNT(receipt_id) FROM receipts''') cursor.execute('''SELECT COUNT(receipt_id) FROM receipts''')
@ -165,3 +172,9 @@ class TestMigrations(unittest.TestCase):
self.assertEqual('testadmin', cursor.fetchone()[0]) self.assertEqual('testadmin', cursor.fetchone()[0])
cursor.execute('''SELECT agent FROM modifications WHERE ta_id = 3''') cursor.execute('''SELECT agent FROM modifications WHERE ta_id = 3''')
self.assertEqual('<unknown>', cursor.fetchone()[0]) self.assertEqual('<unknown>', cursor.fetchone()[0])
# Make sure the consumptions table was changed to contain the product name, or a fallback
cursor.execute('''SELECT product FROM consumptions WHERE ta_id = 4''')
self.assertEqual('Flora Power Mate', cursor.fetchone()[0])
cursor.execute('''SELECT product FROM consumptions WHERE ta_id = 5''')
self.assertEqual('<unknown>', cursor.fetchone()[0])