1
1

create_triggers.py 14 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276
  1. import sqlite3
  2. from typing import List
  3. from game import MINIMUM_ORDER_AMOUNT, CURRENCY_NAME
  4. def create_triggers(cursor: sqlite3.Cursor):
  5. print(' - Creating triggers...')
  6. # ensure that the internal rowids of any table are not updated after creation
  7. create_triggers_that_restrict_rowid_update(cursor)
  8. cursor.execute(f'''
  9. CREATE TRIGGER IF NOT EXISTS owned_amount_not_negative_after_insert
  10. AFTER INSERT ON ownership
  11. WHEN NEW.amount < 0 AND (SELECT name FROM ownables WHERE ownables.rowid = NEW.ownable_id) != '{CURRENCY_NAME}'
  12. BEGIN SELECT RAISE(ROLLBACK, 'Can not own an amount less than 0 (except {CURRENCY_NAME}).'); END
  13. ''')
  14. cursor.execute(f'''
  15. CREATE TRIGGER IF NOT EXISTS owned_amount_not_negative_after_update
  16. AFTER UPDATE ON ownership
  17. WHEN NEW.amount < 0 AND (SELECT name FROM ownables WHERE ownables.rowid = NEW.ownable_id) != '{CURRENCY_NAME}'
  18. BEGIN SELECT RAISE(ROLLBACK, 'Can not own an amount less than 0 (except {CURRENCY_NAME}).'); END
  19. ''')
  20. cursor.execute('''
  21. CREATE TRIGGER IF NOT EXISTS amount_positive_after_insert
  22. AFTER INSERT ON transactions
  23. WHEN NEW.amount <= 0
  24. BEGIN SELECT RAISE(ROLLBACK, 'Can not perform empty transactions.'); END
  25. ''')
  26. cursor.execute('''
  27. CREATE TRIGGER IF NOT EXISTS amount_positive_after_update
  28. AFTER UPDATE ON transactions
  29. WHEN NEW.amount <= 0
  30. BEGIN SELECT RAISE(ROLLBACK, 'Can not perform empty transactions.'); END
  31. ''')
  32. cursor.execute('''
  33. CREATE TRIGGER IF NOT EXISTS order_limit_not_negative_after_insert
  34. AFTER INSERT ON orders
  35. WHEN NEW."limit" IS NOT NULL AND NEW."limit" < 0
  36. BEGIN SELECT RAISE(ROLLBACK, 'Can not set a limit less than 0.'); END
  37. ''')
  38. cursor.execute('''
  39. CREATE TRIGGER IF NOT EXISTS order_limit_not_negative_after_update
  40. AFTER UPDATE ON orders
  41. WHEN NEW."limit" IS NOT NULL AND NEW."limit" < 0
  42. BEGIN SELECT RAISE(ROLLBACK, 'Can not set a limit less than 0.'); END
  43. ''')
  44. cursor.execute('''
  45. CREATE TRIGGER IF NOT EXISTS order_amount_positive_after_insert
  46. AFTER INSERT ON orders
  47. WHEN NEW.ordered_amount <= 0 OR NEW.executed_amount < 0
  48. BEGIN SELECT RAISE(ROLLBACK, 'Can not order 0 or less.'); END
  49. ''')
  50. cursor.execute('''
  51. CREATE TRIGGER IF NOT EXISTS order_amount_positive_after_update
  52. AFTER UPDATE ON orders
  53. WHEN NEW.ordered_amount <= 0 OR NEW.executed_amount < 0
  54. BEGIN SELECT RAISE(ROLLBACK, 'Can not order 0 or less.'); END
  55. ''')
  56. cursor.execute('''
  57. CREATE TRIGGER IF NOT EXISTS stop_loss_order_not_ioc_after_insert
  58. AFTER INSERT ON orders
  59. WHEN NEW.stop_loss AND NEW.ioc
  60. BEGIN SELECT RAISE(ROLLBACK, 'Stop-loss orders can not be Immediate-or-cancel.'); END
  61. ''')
  62. cursor.execute('''
  63. CREATE TRIGGER IF NOT EXISTS stop_loss_order_not_ioc_after_update
  64. AFTER UPDATE ON orders
  65. WHEN NEW.stop_loss AND NEW.ioc
  66. BEGIN SELECT RAISE(ROLLBACK, 'Stop-loss orders can not be Immediate-or-cancel.'); END
  67. ''')
  68. cursor.execute('''
  69. CREATE TRIGGER IF NOT EXISTS not_more_executed_than_ordered_after_insert
  70. AFTER INSERT ON orders
  71. WHEN NEW.ordered_amount < NEW.executed_amount
  72. BEGIN SELECT RAISE(ROLLBACK, 'Can not execute more than ordered.'); END
  73. ''')
  74. cursor.execute('''
  75. CREATE TRIGGER IF NOT EXISTS not_more_executed_than_ordered_after_update
  76. AFTER UPDATE ON orders
  77. WHEN NEW.ordered_amount < NEW.executed_amount
  78. BEGIN SELECT RAISE(ROLLBACK, 'Can not execute more than ordered.'); END
  79. ''')
  80. cursor.execute('''
  81. CREATE TRIGGER IF NOT EXISTS not_more_ordered_than_available_after_insert
  82. AFTER INSERT ON orders
  83. WHEN NOT NEW.buy AND 0 >
  84. -- owned_amount
  85. COALESCE (
  86. (SELECT amount
  87. FROM ownership
  88. WHERE ownership.rowid = NEW.ownership_id), 0)
  89. - -- sell_ordered_amount
  90. (SELECT COALESCE(SUM(orders.ordered_amount - orders.executed_amount),0)
  91. FROM orders, ownership
  92. WHERE ownership.rowid = orders.ownership_id
  93. AND ownership.rowid = NEW.ownership_id
  94. AND NOT orders.buy)
  95. BEGIN SELECT RAISE(ROLLBACK, 'Can not order more than you own.'); END
  96. ''')
  97. cursor.execute('''
  98. CREATE TRIGGER IF NOT EXISTS not_more_ordered_than_available_after_update
  99. AFTER UPDATE ON orders
  100. WHEN NOT NEW.buy AND 0 >
  101. -- owned_amount
  102. COALESCE (
  103. (SELECT amount
  104. FROM ownership
  105. WHERE ownership.rowid = NEW.ownership_id), 0)
  106. - -- sell_ordered_amount
  107. (SELECT COALESCE(SUM(orders.ordered_amount - orders.executed_amount),0)
  108. FROM orders, ownership
  109. WHERE ownership.rowid = orders.ownership_id
  110. AND ownership.rowid = NEW.ownership_id
  111. AND NOT orders.buy)
  112. BEGIN SELECT RAISE(ROLLBACK, 'Can not order more than you own.'); END
  113. ''')
  114. cursor.execute('''
  115. CREATE TRIGGER IF NOT EXISTS expiry_dt_in_future_after_insert
  116. AFTER INSERT ON orders
  117. WHEN NEW.expiry_dt <= CAST(strftime('%s', CURRENT_TIMESTAMP) AS INTEGER)
  118. BEGIN SELECT RAISE(ROLLBACK, 'Order is already expired.'); END
  119. ''')
  120. cursor.execute('''
  121. CREATE TRIGGER IF NOT EXISTS expiry_dt_in_future_after_update
  122. AFTER UPDATE ON orders
  123. WHEN NEW.expiry_dt <= CAST(strftime('%s', CURRENT_TIMESTAMP) AS INTEGER)
  124. BEGIN SELECT RAISE(ROLLBACK, 'Order is already expired.'); END
  125. ''')
  126. cursor.execute('''
  127. CREATE TRIGGER IF NOT EXISTS stop_loss_requires_limit_after_insert
  128. AFTER INSERT ON orders
  129. WHEN NEW."limit" IS NULL AND NEW.stop_loss IS NOT NULL
  130. BEGIN SELECT RAISE(ROLLBACK, 'Can only set `stop_loss` `for limit orders.'); END
  131. ''')
  132. cursor.execute('''
  133. CREATE TRIGGER IF NOT EXISTS stop_loss_requires_limit_after_update
  134. AFTER UPDATE ON orders
  135. WHEN NEW."limit" IS NULL AND NEW.stop_loss IS NOT NULL
  136. BEGIN SELECT RAISE(ROLLBACK, 'Can only set `stop_loss` `for limit orders.'); END
  137. ''')
  138. cursor.execute('''
  139. CREATE TRIGGER IF NOT EXISTS limit_requires_stop_loss_after_insert
  140. AFTER INSERT ON orders
  141. WHEN NEW."limit" IS NOT NULL AND NEW.stop_loss IS NULL
  142. BEGIN SELECT RAISE(ROLLBACK, 'Need to set stop_loss to either True or False for limit orders.'); END
  143. ''')
  144. cursor.execute('''
  145. CREATE TRIGGER IF NOT EXISTS limit_requires_stop_loss_after_update
  146. AFTER UPDATE ON orders
  147. WHEN NEW."limit" IS NOT NULL AND NEW.stop_loss IS NULL
  148. BEGIN SELECT RAISE(ROLLBACK, 'Need to set stop_loss to either True or False for limit orders.'); END
  149. ''')
  150. cursor.execute('''
  151. CREATE TRIGGER IF NOT EXISTS minimum_order_amount_after_insert
  152. AFTER INSERT ON orders
  153. WHEN NEW.ordered_amount < ?
  154. BEGIN SELECT RAISE(ROLLBACK, 'There is a minimum amount for new orders.'); END
  155. '''.replace('?', str(MINIMUM_ORDER_AMOUNT)))
  156. cursor.execute('''
  157. CREATE TRIGGER IF NOT EXISTS integer_amount_after_insert
  158. AFTER INSERT ON orders
  159. WHEN NEW.ordered_amount <> ROUND(NEW.ordered_amount)
  160. BEGIN SELECT RAISE(ROLLBACK, 'Can only set integer amounts for new orders.'); END
  161. '''.replace('?', str(MINIMUM_ORDER_AMOUNT)))
  162. cursor.execute('''
  163. CREATE TRIGGER IF NOT EXISTS dt_monotonic_after_insert
  164. AFTER INSERT ON transactions
  165. WHEN NEW.dt < (SELECT MAX(dt) FROM transactions t2 WHERE t2.rowid < rowid)
  166. BEGIN SELECT RAISE(ROLLBACK, 'Transaction rowid programming bug, not your fault.'); END
  167. ''')
  168. cursor.execute('''
  169. CREATE TRIGGER IF NOT EXISTS dt_monotonic_after_update
  170. AFTER INSERT ON transactions
  171. WHEN NEW.dt < (SELECT MAX(dt) FROM transactions t2 WHERE t2.rowid < rowid)
  172. BEGIN SELECT RAISE(ROLLBACK, 'Transaction rowid programming bug, not your fault.'); END
  173. ''')
  174. cursor.execute('''
  175. CREATE TRIGGER IF NOT EXISTS news_dt_monotonic_after_insert
  176. AFTER INSERT ON news
  177. WHEN NEW.dt < (SELECT MAX(dt) FROM news t2 WHERE t2.rowid < rowid)
  178. BEGIN SELECT RAISE(ROLLBACK, 'Transaction rowid programming bug, not your fault.'); END
  179. ''')
  180. cursor.execute('''
  181. CREATE TRIGGER IF NOT EXISTS news_dt_monotonic_after_insert
  182. AFTER INSERT ON news
  183. WHEN NEW.dt < (SELECT MAX(dt) FROM news t2 WHERE t2.rowid < rowid)
  184. BEGIN SELECT RAISE(ROLLBACK, 'Transaction rowid programming bug, not your fault.'); END
  185. ''')
  186. cursor.execute('''
  187. CREATE TRIGGER IF NOT EXISTS orders_rowid_sorted_by_creation_time_after_insert
  188. AFTER INSERT ON orders
  189. WHEN NEW.rowid < (SELECT MAX(rowid) FROM orders o2)
  190. BEGIN SELECT RAISE(ROLLBACK, 'Order-rowid programming bug (insert), not your fault.'); END
  191. ''')
  192. cursor.execute('''
  193. CREATE TRIGGER IF NOT EXISTS news_dt_monotonic_after_update
  194. AFTER UPDATE ON orders
  195. WHEN NEW.rowid <> OLD.rowid
  196. BEGIN SELECT RAISE(ROLLBACK, 'Cannot change number of existing order.'); END
  197. ''')
  198. cursor.execute('''
  199. CREATE TRIGGER IF NOT EXISTS not_nullify_buyer_id_after_update
  200. AFTER UPDATE ON transactions
  201. WHEN NEW.buyer_id IS NULL AND OLD.buyer_id IS NOT NULL
  202. BEGIN SELECT RAISE(ROLLBACK, 'Cannot nullify buyer_id.'); END
  203. ''')
  204. cursor.execute('''
  205. CREATE TRIGGER IF NOT EXISTS buyer_id_not_null_after_insert
  206. AFTER INSERT ON transactions
  207. WHEN NEW.buyer_id IS NULL
  208. BEGIN SELECT RAISE(ROLLBACK, 'buyer_id must not be null for new transactions.'); END
  209. ''')
  210. cursor.execute('''
  211. CREATE TRIGGER IF NOT EXISTS not_nullify_seller_id_after_update
  212. AFTER UPDATE ON transactions
  213. WHEN NEW.seller_id IS NULL AND OLD.seller_id IS NOT NULL
  214. BEGIN SELECT RAISE(ROLLBACK, 'Cannot nullify seller_id.'); END
  215. ''')
  216. cursor.execute('''
  217. CREATE TRIGGER IF NOT EXISTS seller_id_not_null_after_insert
  218. AFTER INSERT ON transactions
  219. WHEN NEW.seller_id IS NULL
  220. BEGIN SELECT RAISE(ROLLBACK, 'seller_id must not be null for new transactions.'); END
  221. ''')
  222. cursor.execute('''
  223. CREATE TRIGGER IF NOT EXISTS order_history_no_update
  224. BEFORE UPDATE ON order_history
  225. BEGIN SELECT RAISE(ROLLBACK, 'Can not change order history.'); END
  226. ''')
  227. def create_combination_cluster_triggers(cursor: sqlite3.Cursor,
  228. table_name: str,
  229. foreign_key_column_name: str,
  230. referenced_tables: List[str],
  231. kind_column_name: str = 'kind',):
  232. valid_kind = '\n OR '.join("(NEW.{0} = '{1}' AND EXISTS (SELECT * FROM {1} WHERE rowid = NEW.{2}))"
  233. .format(kind_column_name, table, foreign_key_column_name)
  234. for table in referenced_tables)
  235. cursor.execute('''-- noinspection SqlResolveForFile
  236. CREATE TRIGGER valid_{0}_{1}_after_insert
  237. AFTER INSERT ON {0}
  238. WHEN NOT ({2})
  239. BEGIN SELECT RAISE(ROLLBACK, '{0}.{1} is invalid or violating a foreign key constraint.'); END
  240. '''.format(table_name, kind_column_name, valid_kind))
  241. cursor.execute('''-- noinspection SqlResolveForFile
  242. CREATE TRIGGER valid_{0}_{1}_after_update
  243. AFTER UPDATE ON {0}
  244. WHEN NOT ({2})
  245. BEGIN SELECT RAISE(ROLLBACK, '{0}.{1} is invalid or violating a foreign key constraint.'); END
  246. '''.format(table_name, kind_column_name, valid_kind))
  247. for referenced_table in referenced_tables:
  248. cursor.execute('''-- noinspection SqlResolveForFile
  249. CREATE TRIGGER IF NOT EXISTS {0}_{1}_{3}_foreign_key_before_delete
  250. BEFORE DELETE ON {3}
  251. WHEN EXISTS (
  252. SELECT * FROM {0}
  253. WHERE {0}.{4} = OLD.rowid
  254. AND {0}.{1} = '{3}'
  255. )
  256. BEGIN SELECT RAISE(ROLLBACK, '{0}.{1} is violating a foreign key constraint.'); END
  257. '''.format(table_name, kind_column_name, valid_kind, referenced_table, foreign_key_column_name))
  258. def create_triggers_that_restrict_rowid_update(cursor):
  259. cursor.execute('''
  260. SELECT name FROM sqlite_master WHERE type='table'
  261. ''')
  262. tables = [row[0] for row in cursor.fetchall()]
  263. for table_name in tables:
  264. cursor.execute('''-- noinspection SqlResolveForFile
  265. CREATE TRIGGER IF NOT EXISTS restrict_rowid_update_on_{0}
  266. AFTER UPDATE ON {0}
  267. WHEN OLD.rowid <> NEW.rowid
  268. BEGIN SELECT RAISE(ROLLBACK, 'The rowid can not be changed.'); END
  269. '''.format(table_name))