Przeglądaj źródła

add some cool indices and optimize database queries

Eren Yilmaz 6 lat temu
rodzic
commit
260569c3cf
3 zmienionych plików z 97 dodań i 26 usunięć
  1. 10 4
      cool_query.py
  2. 74 2
      db_setup.py
  3. 13 20
      model.py

+ 10 - 4
cool_query.py

@@ -1,9 +1,15 @@
 import model
+from client_controller import _my_tabulate
 
 model.connect()
 model.cursor.execute('''
-        SELECT * FROM users 
-                WHERE username = ?
-        ''',('u',))
+        EXPLAIN QUERY PLAN 
+                DELETE FROM sessions
+                WHERE 
+                    (SELECT COUNT(*) as newer
+                     FROM sessions s2
+                     WHERE user_id = s2.user_id
+                     AND rowid < s2.rowid) >= 10
+        '''.replace('?','1'))
 
-print(model.cursor.fetchall())
+print(_my_tabulate(model.cursor.fetchall(),tablefmt='pipe'))

+ 74 - 2
db_setup.py

@@ -10,6 +10,8 @@ def setup(cursor, seed_tables=False):
 
     create_triggers(cursor)
 
+    create_indices(cursor)
+
     if seed_tables:
         seed(cursor)
 
@@ -34,6 +36,8 @@ def drop_triggers(cursor):
     cursor.execute("DROP TRIGGER IF EXISTS limit_requires_stop_loss_after_update")
     cursor.execute("DROP TRIGGER IF EXISTS minimum_order_amount_after_insert")
     cursor.execute("DROP TRIGGER IF EXISTS integer_amount_after_insert")
+    cursor.execute("DROP TRIGGER IF EXISTS dt_monotonic_after_insert")
+    cursor.execute("DROP TRIGGER IF EXISTS dt_monotonic_after_update")
 
 
 # def drop_database(cursor):
@@ -171,13 +175,81 @@ def create_triggers(cursor):
                 AFTER INSERT ON orders
                 WHEN NEW.ordered_amount < ?
                 BEGIN SELECT RAISE(ROLLBACK, 'There is a minimum amount for new orders.'); END
-                '''.replace('?',str(MINIMUM_ORDER_AMOUNT)))
+                '''.replace('?', str(MINIMUM_ORDER_AMOUNT)))
     cursor.execute('''
                 CREATE TRIGGER IF NOT EXISTS integer_amount_after_insert
                 AFTER INSERT ON orders
                 WHEN NEW.ordered_amount <> ROUND(NEW.ordered_amount)
                 BEGIN SELECT RAISE(ROLLBACK, 'Can only set integer amounts for new orders.'); END
-                '''.replace('?',str(MINIMUM_ORDER_AMOUNT)))
+                '''.replace('?', str(MINIMUM_ORDER_AMOUNT)))
+    cursor.execute('''
+                CREATE TRIGGER IF NOT EXISTS dt_monotonic_after_insert
+                AFTER INSERT ON transactions
+                WHEN NEW.dt < (SELECT MAX(dt) FROM transactions t2 WHERE t2.rowid < rowid)
+                BEGIN SELECT RAISE(ROLLBACK, 'Transaction rowid programming bug, not your fault.'); END
+                ''')
+    cursor.execute('''
+                CREATE TRIGGER IF NOT EXISTS dt_monotonic_after_update
+                AFTER INSERT ON transactions
+                WHEN NEW.dt < (SELECT MAX(dt) FROM transactions t2 WHERE t2.rowid < rowid)
+                BEGIN SELECT RAISE(ROLLBACK, 'Transaction rowid programming bug, not your fault.'); END
+                ''')
+    cursor.execute('''
+                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
+                ''')
+    cursor.execute('''
+                CREATE TRIGGER IF NOT EXISTS news_dt_monotonic_after_update
+                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
+                ''')
+
+
+def create_indices(cursor):
+    print(' - Creating indices...')
+    cursor.execute('''
+                CREATE INDEX IF NOT EXISTS ownership_ownable
+                ON ownership (ownable_id)
+                ''')
+    cursor.execute('''
+                CREATE INDEX IF NOT EXISTS transactions_ownable
+                ON transactions (ownable_id)
+                ''')
+    cursor.execute('''
+                CREATE INDEX IF NOT EXISTS orders_expiry
+                ON orders (expiry_dt)
+                ''')
+    cursor.execute('''
+                CREATE INDEX IF NOT EXISTS orders_ownership
+                ON orders (ownership_id)
+                ''')
+    cursor.execute('''
+                CREATE INDEX IF NOT EXISTS transactions_dt
+                ON transactions (dt)
+                ''')
+    cursor.execute('''
+                CREATE INDEX IF NOT EXISTS news_dt
+                ON news (dt)
+                ''')
+    cursor.execute('''
+                CREATE INDEX IF NOT EXISTS ownables_name
+                ON ownables (name)
+                ''')
+    cursor.execute('''
+                CREATE INDEX IF NOT EXISTS users_name
+                ON users (username)
+                ''')
+    cursor.execute('''
+                CREATE INDEX IF NOT EXISTS sessions_id
+                ON sessions (session_id)
+                ''')
+    cursor.execute('''
+                CREATE INDEX IF NOT EXISTS sessions_user
+                ON sessions (user_id)
+                ''')
 
 
 def tables(cursor):

+ 13 - 20
model.py

@@ -75,7 +75,7 @@ def used_key_count():
     connect()
 
     cursor.execute('''
-        SELECT COUNT(*)
+        SELECT COUNT(*) -- rarely executed, no index needed, O(n) query
         FROM keys
         WHERE used_by_user_id IS NOT NULL
         ''')
@@ -130,16 +130,8 @@ def own(user_id, ownable_name):
         return AssertionError('A name must be a string.')
 
     cursor.execute('''
-                WITH one_ownable_id AS (SELECT rowid FROM ownables WHERE name = ?),
-                     one_user_id AS (SELECT ?)
-                INSERT INTO ownership (user_id, ownable_id)
-                SELECT *
-                FROM one_user_id, one_ownable_id
-                WHERE NOT EXISTS (
-                    SELECT * FROM ownership
-                    WHERE ownership.user_id IN one_user_id
-                    AND ownership.ownable_id IN one_ownable_id
-                )
+                INSERT OR IGNORE INTO ownership (user_id, ownable_id)
+                SELECT ?, (SELECT rowid FROM ownables WHERE name = ?)
                 ''', (ownable_name, user_id,))
 
 
@@ -287,7 +279,7 @@ def get_user_ownership(user_id):
             ELSE (SELECT price 
                   FROM transactions
                   WHERE ownable_id = ownership.ownable_id 
-                  ORDER BY dt DESC 
+                  ORDER BY rowid DESC -- equivalent to ordering by dt
                   LIMIT 1)
             END, 0) AS price, 
             (SELECT MAX("limit") 
@@ -464,7 +456,7 @@ def news():
         SELECT * FROM
             (SELECT *
             FROM news
-            ORDER BY dt DESC
+            ORDER BY rowid DESC -- equivalent to order by dt
             LIMIT 20) n
         ORDER BY dt ASC
         ''')
@@ -595,7 +587,7 @@ def current_value(ownable_id):
     cursor.execute('''SELECT price 
                       FROM transactions
                       WHERE ownable_id = ?
-                      ORDER BY dt DESC 
+                      ORDER BY rowid DESC -- equivalent to order by dt 
                       LIMIT 1
         ''', (ownable_id,))
     return cursor.fetchone()[0]
@@ -719,6 +711,7 @@ def execute_orders(ownable_id):
 
         # trigger stop-loss orders
         if buyer_id != seller_id:
+            # todo optimize this query, very slow like this
             cursor.execute('''
                 UPDATE orders
                 SET stop_loss = NULL,
@@ -770,7 +763,7 @@ def bank_order(buy, ownable_id, limit, amount, time_until_expiration):
         ''', ('External investors are selling ' + ownable_name + ' atm',))
 
 
-def current_time():  # might differ from datetime.datetime.now() for time zone reasons
+def current_db_time():  # might differ from datetime.datetime.now() for time zone reasons
     connect()
 
     cursor.execute('''
@@ -782,7 +775,7 @@ def current_time():  # might differ from datetime.datetime.now() for time zone r
 
 def place_order(buy, ownership_id, limit, stop_loss, amount, time_until_expiration):
     connect()
-    expiry = datetime.strptime(current_time(), '%Y-%m-%d %H:%M:%S') + timedelta(minutes=time_until_expiration)
+    expiry = datetime.strptime(current_db_time(), '%Y-%m-%d %H:%M:%S') + timedelta(minutes=time_until_expiration)
 
     cursor.execute('''
                 INSERT INTO orders 
@@ -801,7 +794,7 @@ def transactions(ownable_id):
         SELECT dt, amount, price
         FROM transactions
         WHERE ownable_id = ?
-        ORDER BY dt DESC
+        ORDER BY rowid DESC -- equivalent to order by dt
         ''', (ownable_id,))
 
     return cursor.fetchall()
@@ -858,7 +851,7 @@ def leaderboard():
                     ELSE ownership.amount * (SELECT price 
                                              FROM transactions
                                              WHERE ownable_id = ownership.ownable_id 
-                                             ORDER BY dt DESC 
+                                             ORDER BY rowid DESC -- equivalent to ordering by dt
                                              LIMIT 1)
                     END
                 ) score
@@ -884,7 +877,7 @@ def user_wealth(user_id):
             ELSE ownership.amount * (SELECT price 
                                      FROM transactions
                                      WHERE ownable_id = ownership.ownable_id 
-                                     ORDER BY dt DESC 
+                                     ORDER BY rowid DESC -- equivalent to ordering by dt
                                      LIMIT 1)
             END
         ) score
@@ -901,7 +894,7 @@ def change_password(session_id, password):
     cursor.execute('''
                 UPDATE users
                 SET password = ?
-                WHERE ? IN (SELECT session_id FROM sessions WHERE sessions.user_id = users.rowid)
+                WHERE rowid = (SELECT user_id FROM sessions WHERE sessions.session_id = ?)
                 ''', (password, session_id,))