Browse Source

Add db column for seller and buyer for transactions

Eren Yilmaz 6 years ago
parent
commit
77934fec52
2 changed files with 79 additions and 20 deletions
  1. 75 16
      db_setup.py
  2. 4 4
      model.py

+ 75 - 16
db_setup.py

@@ -1,3 +1,5 @@
+from sqlite3 import OperationalError
+
 from game import CURRENCY_NAME, MINIMUM_ORDER_AMOUNT
 
 
@@ -41,7 +43,10 @@ def drop_triggers(cursor):
     cursor.execute("DROP TRIGGER IF EXISTS dt_monotonic_after_update")
     cursor.execute("DROP TRIGGER IF EXISTS orders_rowid_sorted_by_creation_time_after_insert")
     cursor.execute("DROP TRIGGER IF EXISTS news_dt_monotonic_after_update")
-
+    cursor.execute("DROP TRIGGER IF EXISTS not_nullify_buyer_id_after_update")
+    cursor.execute("DROP TRIGGER IF EXISTS buyer_id_not_null_after_insert")
+    cursor.execute("DROP TRIGGER IF EXISTS not_nullify_seller_id_after_update")
+    cursor.execute("DROP TRIGGER IF EXISTS seller_id_not_null_after_insert")
 
 # def drop_database(cursor):
 #     print(' - Dropping old tables...')
@@ -158,34 +163,36 @@ def create_triggers(cursor):
     cursor.execute('''
                 CREATE TRIGGER IF NOT EXISTS not_more_ordered_than_available_after_insert
                 AFTER INSERT ON orders
-                WHEN 0 >
-                    -- sell_ordered_amount
+                WHEN NOT NEW.buy AND 0 >
+                    -- owned_amount
+                    COALESCE (
+                        (SELECT amount
+                         FROM ownership
+                         WHERE ownership.rowid = NEW.ownership_id), 0)
+                    - -- sell_ordered_amount
                     (SELECT COALESCE(SUM(orders.ordered_amount - orders.executed_amount),0)
                      FROM orders, ownership
                      WHERE ownership.rowid = orders.ownership_id
                      AND ownership.rowid = NEW.ownership_id
                      AND NOT orders.buy) 
-                    - -- owned_amount
-                    (SELECT COALESCE(amount, 0)
-                     FROM ownership
-                     WHERE ownership.rowid = NEW.ownership_id)
-                BEGIN SELECT RAISE(ROLLBACK, 'Can not order more than you own available.'); END
+                BEGIN SELECT RAISE(ROLLBACK, 'Can not order more than you own.'); END
                 ''')
     cursor.execute('''
                 CREATE TRIGGER IF NOT EXISTS not_more_ordered_than_available_after_update
                 AFTER UPDATE ON orders
-                WHEN 0 >
-                    -- sell_ordered_amount
+                WHEN NOT NEW.buy AND 0 >
+                    -- owned_amount
+                    COALESCE (
+                        (SELECT amount
+                         FROM ownership
+                         WHERE ownership.rowid = NEW.ownership_id), 0)
+                    - -- sell_ordered_amount
                     (SELECT COALESCE(SUM(orders.ordered_amount - orders.executed_amount),0)
                      FROM orders, ownership
                      WHERE ownership.rowid = orders.ownership_id
                      AND ownership.rowid = NEW.ownership_id
                      AND NOT orders.buy) 
-                    - -- owned_amount
-                    (SELECT COALESCE(amount, 0)
-                     FROM ownership
-                     WHERE ownership.rowid = NEW.ownership_id)
-                BEGIN SELECT RAISE(ROLLBACK, 'Can not order more than you own available.'); END
+                BEGIN SELECT RAISE(ROLLBACK, 'Can not order more than you own.'); END
                 ''')
     cursor.execute('''
                 CREATE TRIGGER IF NOT EXISTS expiry_dt_in_future_after_insert
@@ -254,7 +261,7 @@ def create_triggers(cursor):
                 BEGIN SELECT RAISE(ROLLBACK, 'Transaction rowid programming bug, not your fault.'); END
                 ''')
     cursor.execute('''
-                CREATE TRIGGER IF NOT EXISTS news_dt_monotonic_after_update
+                CREATE TRIGGER IF NOT EXISTS news_dt_monotonic_after_insert
                 AFTER INSERT ON news
                 WHEN NEW.dt < (SELECT MAX(dt) FROM news t2 WHERE t2.rowid < rowid)
                 BEGIN SELECT RAISE(ROLLBACK, 'Transaction rowid programming bug, not your fault.'); END
@@ -271,6 +278,30 @@ def create_triggers(cursor):
                 WHEN NEW.rowid <> OLD.rowid
                 BEGIN SELECT RAISE(ROLLBACK, 'Cannot change number of existing order.'); END
                 ''')
+    cursor.execute('''
+                CREATE TRIGGER IF NOT EXISTS not_nullify_buyer_id_after_update
+                AFTER UPDATE ON transactions
+                WHEN NEW.buyer_id IS NULL AND OLD.buyer_id IS NOT NULL
+                BEGIN SELECT RAISE(ROLLBACK, 'Cannot nullify buyer_id.'); END
+                ''')
+    cursor.execute('''
+                CREATE TRIGGER IF NOT EXISTS buyer_id_not_null_after_insert
+                AFTER INSERT ON transactions
+                WHEN NEW.buyer_id IS NULL
+                BEGIN SELECT RAISE(ROLLBACK, 'buyer_id must not be null for new transactions.'); END
+                ''')
+    cursor.execute('''
+                CREATE TRIGGER IF NOT EXISTS not_nullify_seller_id_after_update
+                AFTER UPDATE ON transactions
+                WHEN NEW.seller_id IS NULL AND OLD.seller_id IS NOT NULL
+                BEGIN SELECT RAISE(ROLLBACK, 'Cannot nullify seller_id.'); END
+                ''')
+    cursor.execute('''
+                CREATE TRIGGER IF NOT EXISTS seller_id_not_null_after_insert
+                AFTER INSERT ON transactions
+                WHEN NEW.seller_id IS NULL
+                BEGIN SELECT RAISE(ROLLBACK, 'seller_id must not be null for new transactions.'); END
+                ''')
 
 
 def create_indices(cursor):
@@ -319,6 +350,14 @@ def create_indices(cursor):
                 CREATE INDEX IF NOT EXISTS sessions_user
                 ON sessions (user_id)
                 ''')
+    cursor.execute('''
+                CREATE INDEX IF NOT EXISTS transactions_seller
+                ON transactions (seller_id)
+                ''')
+    cursor.execute('''
+                CREATE INDEX IF NOT EXISTS transactions_buyer
+                ON transactions (buyer_id)
+                ''')
 
 
 def tables(cursor):
@@ -370,6 +409,14 @@ def tables(cursor):
                     FOREIGN KEY (ownable_id) REFERENCES ownable(rowid)
                 )
                 ''')
+    _add_column_if_not_exists(cursor, '''
+                -- there is a not null constraint for new values that is watched by triggers
+                ALTER TABLE transactions ADD COLUMN buyer_id INTEGER REFERENCES user(rowid)
+                ''')
+    _add_column_if_not_exists(cursor, '''
+                -- there is a not null constraint for new values that is watched by triggers
+                ALTER TABLE transactions ADD COLUMN seller_id INTEGER REFERENCES user(rowid)
+                ''')
     cursor.execute('''
                 CREATE TABLE IF NOT EXISTS keys(
                     key STRING UNIQUE NOT NULL,
@@ -383,3 +430,15 @@ def tables(cursor):
                     title VARCHAR(50) NOT NULL
                 )
                 ''')
+
+
+def _add_column_if_not_exists(cursor, query):
+    if 'ALTER TABLE' not in query:
+        raise ValueError('Only alter table queries allowed.')
+    if 'ADD COLUMN' not in query:
+        raise ValueError('Only add column queries allowed.')
+    try:
+        cursor.execute(query)
+    except OperationalError as e:  # if the column already exists this will happen
+        if 'duplicate column name' not in e.args[0]:
+            raise

+ 4 - 4
model.py

@@ -8,9 +8,9 @@ from math import floor
 from passlib.handlers.sha2_crypt import sha256_crypt
 
 import db_setup
+from debug import debug
 from game import CURRENCY_NAME
 from util import random_chars, salt
-from debug import debug
 
 # connection: db.Connection = None
 # cursor: db.Cursor = None
@@ -740,9 +740,9 @@ def execute_orders(ownable_id):
         if seller_id != buyer_id:  # prevent showing self-transactions
             cursor.execute('''
                 INSERT INTO transactions
-                (price, ownable_id, amount)
-                VALUES(?, ?, ?)
-                ''', (price, ownable_id, amount,))
+                (price, ownable_id, amount, buyer_id, seller_id)
+                VALUES(?, ?, ?, ?, ?)
+                ''', (price, ownable_id, amount, buyer_id, seller_id))
 
         # trigger stop-loss orders
         if buyer_id != seller_id: