db_setup.py 15 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330
  1. from game import CURRENCY_NAME, MINIMUM_ORDER_AMOUNT
  2. def setup(cursor, seed_tables=False):
  3. print('Database setup...')
  4. drop_triggers(cursor)
  5. tables(cursor)
  6. create_triggers(cursor)
  7. create_indices(cursor)
  8. if seed_tables:
  9. seed(cursor)
  10. def drop_triggers(cursor):
  11. print(' - Dropping all triggers...')
  12. cursor.execute("DROP TRIGGER IF EXISTS owned_amount_not_negative_after_insert")
  13. cursor.execute("DROP TRIGGER IF EXISTS owned_amount_not_negative_after_update")
  14. cursor.execute("DROP TRIGGER IF EXISTS amount_positive_after_insert")
  15. cursor.execute("DROP TRIGGER IF EXISTS amount_positive_after_update")
  16. cursor.execute("DROP TRIGGER IF EXISTS order_limit_not_negative_after_insert")
  17. cursor.execute("DROP TRIGGER IF EXISTS order_limit_not_negative_after_update")
  18. cursor.execute("DROP TRIGGER IF EXISTS order_amount_positive_after_insert")
  19. cursor.execute("DROP TRIGGER IF EXISTS order_amount_positive_after_update")
  20. cursor.execute("DROP TRIGGER IF EXISTS not_more_executed_than_ordered_after_insert")
  21. cursor.execute("DROP TRIGGER IF EXISTS not_more_executed_than_ordered_after_update")
  22. cursor.execute("DROP TRIGGER IF EXISTS expiry_dt_in_future_after_insert")
  23. cursor.execute("DROP TRIGGER IF EXISTS expiry_dt_in_future_after_update")
  24. cursor.execute("DROP TRIGGER IF EXISTS stop_loss_requires_limit_after_insert")
  25. cursor.execute("DROP TRIGGER IF EXISTS stop_loss_requires_limit_after_update")
  26. cursor.execute("DROP TRIGGER IF EXISTS limit_requires_stop_loss_after_insert")
  27. cursor.execute("DROP TRIGGER IF EXISTS limit_requires_stop_loss_after_update")
  28. cursor.execute("DROP TRIGGER IF EXISTS minimum_order_amount_after_insert")
  29. cursor.execute("DROP TRIGGER IF EXISTS integer_amount_after_insert")
  30. cursor.execute("DROP TRIGGER IF EXISTS dt_monotonic_after_insert")
  31. cursor.execute("DROP TRIGGER IF EXISTS dt_monotonic_after_update")
  32. cursor.execute("DROP TRIGGER IF EXISTS orders_rowid_sorted_by_creation_time_after_insert")
  33. cursor.execute("DROP TRIGGER IF EXISTS news_dt_monotonic_after_update")
  34. # def drop_database(cursor):
  35. # print(' - Dropping old tables...')
  36. # cursor.execute("DROP TABLE IF EXISTS users")
  37. # cursor.execute("DROP TABLE IF EXISTS ownables")
  38. # cursor.execute("DROP TABLE IF EXISTS ownership")
  39. # cursor.execute("DROP TABLE IF EXISTS sessions")
  40. # cursor.execute("DROP TABLE IF EXISTS orders")
  41. # cursor.execute("DROP TABLE IF EXISTS transactions")
  42. # cursor.execute("DROP TABLE IF EXISTS keys")
  43. # cursor.execute("DROP TABLE IF EXISTS news")
  44. def seed(cursor):
  45. print(' - Seeding initial data...')
  46. cursor.execute('''
  47. INSERT INTO ownables
  48. (name)
  49. VALUES (?)
  50. ''', (CURRENCY_NAME,))
  51. cursor.execute('''
  52. INSERT INTO users
  53. (username,password)
  54. VALUES ('bank','')
  55. ''')
  56. cursor.execute('''
  57. INSERT INTO ownership
  58. (user_id, ownable_id)
  59. VALUES ((SELECT rowid FROM users WHERE username = 'bank'),
  60. (SELECT rowid FROM ownables WHERE name = ?))
  61. ''', (CURRENCY_NAME,))
  62. def create_triggers(cursor):
  63. print(' - Creating triggers...')
  64. cursor.execute('''
  65. CREATE TRIGGER IF NOT EXISTS owned_amount_not_negative_after_insert
  66. AFTER INSERT ON ownership
  67. WHEN NEW.amount < 0
  68. BEGIN SELECT RAISE(ROLLBACK, 'Can not own an amount less than 0.'); END
  69. ''')
  70. cursor.execute('''
  71. CREATE TRIGGER IF NOT EXISTS owned_amount_not_negative_after_update
  72. AFTER UPDATE ON ownership
  73. WHEN NEW.amount < 0
  74. BEGIN SELECT RAISE(ROLLBACK, 'Can not own an amount less than 0.'); END
  75. ''')
  76. cursor.execute('''
  77. CREATE TRIGGER IF NOT EXISTS amount_positive_after_insert
  78. AFTER INSERT ON transactions
  79. WHEN NEW.amount <= 0
  80. BEGIN SELECT RAISE(ROLLBACK, 'Can not perform empty transactions.'); END
  81. ''')
  82. cursor.execute('''
  83. CREATE TRIGGER IF NOT EXISTS amount_positive_after_update
  84. AFTER UPDATE ON transactions
  85. WHEN NEW.amount <= 0
  86. BEGIN SELECT RAISE(ROLLBACK, 'Can not perform empty transactions.'); END
  87. ''')
  88. cursor.execute('''
  89. CREATE TRIGGER IF NOT EXISTS order_limit_not_negative_after_insert
  90. AFTER INSERT ON orders
  91. WHEN NEW."limit" IS NOT NULL AND NEW."limit" < 0
  92. BEGIN SELECT RAISE(ROLLBACK, 'Can not set a limit less than 0.'); END
  93. ''')
  94. cursor.execute('''
  95. CREATE TRIGGER IF NOT EXISTS order_limit_not_negative_after_update
  96. AFTER UPDATE ON orders
  97. WHEN NEW."limit" IS NOT NULL AND NEW."limit" < 0
  98. BEGIN SELECT RAISE(ROLLBACK, 'Can not set a limit less than 0.'); END
  99. ''')
  100. cursor.execute('''
  101. CREATE TRIGGER IF NOT EXISTS order_amount_positive_after_insert
  102. AFTER INSERT ON orders
  103. WHEN NEW.ordered_amount <= 0 OR NEW.executed_amount < 0
  104. BEGIN SELECT RAISE(ROLLBACK, 'Can not order 0 or less.'); END
  105. ''')
  106. cursor.execute('''
  107. CREATE TRIGGER IF NOT EXISTS order_amount_positive_after_update
  108. AFTER UPDATE ON orders
  109. WHEN NEW.ordered_amount <= 0 OR NEW.executed_amount < 0
  110. BEGIN SELECT RAISE(ROLLBACK, 'Can not order 0 or less.'); END
  111. ''')
  112. cursor.execute('''
  113. CREATE TRIGGER IF NOT EXISTS not_more_executed_than_ordered_after_insert
  114. AFTER INSERT ON orders
  115. WHEN NEW.ordered_amount < NEW.executed_amount
  116. BEGIN SELECT RAISE(ROLLBACK, 'Can not execute more than ordered.'); END
  117. ''')
  118. cursor.execute('''
  119. CREATE TRIGGER IF NOT EXISTS not_more_executed_than_ordered_after_update
  120. AFTER UPDATE ON orders
  121. WHEN NEW.ordered_amount < NEW.executed_amount
  122. BEGIN SELECT RAISE(ROLLBACK, 'Can not execute more than ordered.'); END
  123. ''')
  124. cursor.execute('''
  125. CREATE TRIGGER IF NOT EXISTS expiry_dt_in_future_after_insert
  126. AFTER INSERT ON orders
  127. WHEN NEW.expiry_dt <= datetime('now')
  128. BEGIN SELECT RAISE(ROLLBACK, 'Order is already expired.'); END
  129. ''')
  130. cursor.execute('''
  131. CREATE TRIGGER IF NOT EXISTS expiry_dt_in_future_after_update
  132. AFTER UPDATE ON orders
  133. WHEN NEW.expiry_dt <= datetime('now')
  134. BEGIN SELECT RAISE(ROLLBACK, 'Order is already expired.'); END
  135. ''')
  136. cursor.execute('''
  137. CREATE TRIGGER IF NOT EXISTS stop_loss_requires_limit_after_insert
  138. AFTER INSERT ON orders
  139. WHEN NEW."limit" IS NULL AND NEW.stop_loss IS NOT NULL
  140. BEGIN SELECT RAISE(ROLLBACK, 'Can only set `stop_loss` `for limit orders.'); END
  141. ''')
  142. cursor.execute('''
  143. CREATE TRIGGER IF NOT EXISTS stop_loss_requires_limit_after_update
  144. AFTER UPDATE ON orders
  145. WHEN NEW."limit" IS NULL AND NEW.stop_loss IS NOT NULL
  146. BEGIN SELECT RAISE(ROLLBACK, 'Can only set `stop_loss` `for limit orders.'); END
  147. ''')
  148. cursor.execute('''
  149. CREATE TRIGGER IF NOT EXISTS limit_requires_stop_loss_after_insert
  150. AFTER INSERT ON orders
  151. WHEN NEW."limit" IS NOT NULL AND NEW.stop_loss IS NULL
  152. BEGIN SELECT RAISE(ROLLBACK, 'Need to set stop_loss to either True or False for limit orders.'); END
  153. ''')
  154. cursor.execute('''
  155. CREATE TRIGGER IF NOT EXISTS limit_requires_stop_loss_after_update
  156. AFTER UPDATE ON orders
  157. WHEN NEW."limit" IS NOT NULL AND NEW.stop_loss IS NULL
  158. BEGIN SELECT RAISE(ROLLBACK, 'Need to set stop_loss to either True or False for limit orders.'); END
  159. ''')
  160. cursor.execute('''
  161. CREATE TRIGGER IF NOT EXISTS minimum_order_amount_after_insert
  162. AFTER INSERT ON orders
  163. WHEN NEW.ordered_amount < ?
  164. BEGIN SELECT RAISE(ROLLBACK, 'There is a minimum amount for new orders.'); END
  165. '''.replace('?', str(MINIMUM_ORDER_AMOUNT)))
  166. cursor.execute('''
  167. CREATE TRIGGER IF NOT EXISTS integer_amount_after_insert
  168. AFTER INSERT ON orders
  169. WHEN NEW.ordered_amount <> ROUND(NEW.ordered_amount)
  170. BEGIN SELECT RAISE(ROLLBACK, 'Can only set integer amounts for new orders.'); END
  171. '''.replace('?', str(MINIMUM_ORDER_AMOUNT)))
  172. cursor.execute('''
  173. CREATE TRIGGER IF NOT EXISTS dt_monotonic_after_insert
  174. AFTER INSERT ON transactions
  175. WHEN NEW.dt < (SELECT MAX(dt) FROM transactions t2 WHERE t2.rowid < rowid)
  176. BEGIN SELECT RAISE(ROLLBACK, 'Transaction rowid programming bug, not your fault.'); END
  177. ''')
  178. cursor.execute('''
  179. CREATE TRIGGER IF NOT EXISTS dt_monotonic_after_update
  180. AFTER INSERT ON transactions
  181. WHEN NEW.dt < (SELECT MAX(dt) FROM transactions t2 WHERE t2.rowid < rowid)
  182. BEGIN SELECT RAISE(ROLLBACK, 'Transaction rowid programming bug, not your fault.'); END
  183. ''')
  184. cursor.execute('''
  185. CREATE TRIGGER IF NOT EXISTS news_dt_monotonic_after_insert
  186. AFTER INSERT ON news
  187. WHEN NEW.dt < (SELECT MAX(dt) FROM news t2 WHERE t2.rowid < rowid)
  188. BEGIN SELECT RAISE(ROLLBACK, 'Transaction rowid programming bug, not your fault.'); END
  189. ''')
  190. cursor.execute('''
  191. CREATE TRIGGER IF NOT EXISTS news_dt_monotonic_after_update
  192. AFTER INSERT ON news
  193. WHEN NEW.dt < (SELECT MAX(dt) FROM news t2 WHERE t2.rowid < rowid)
  194. BEGIN SELECT RAISE(ROLLBACK, 'Transaction rowid programming bug, not your fault.'); END
  195. ''')
  196. cursor.execute('''
  197. CREATE TRIGGER IF NOT EXISTS orders_rowid_sorted_by_creation_time_after_insert
  198. AFTER INSERT ON orders
  199. WHEN NEW.rowid < (SELECT MAX(rowid) FROM orders o2)
  200. BEGIN SELECT RAISE(ROLLBACK, 'Order-rowid programming bug (insert), not your fault.'); END
  201. ''')
  202. cursor.execute('''
  203. CREATE TRIGGER IF NOT EXISTS news_dt_monotonic_after_update
  204. AFTER UPDATE ON orders
  205. WHEN NEW.rowid <> OLD.rowid
  206. BEGIN SELECT RAISE(ROLLBACK, 'Cannot change number of existing order.'); END
  207. ''')
  208. def create_indices(cursor):
  209. print(' - Creating indices...')
  210. cursor.execute('''
  211. CREATE INDEX IF NOT EXISTS ownership_ownable
  212. ON ownership (ownable_id)
  213. ''')
  214. cursor.execute('''
  215. CREATE INDEX IF NOT EXISTS transactions_ownable
  216. ON transactions (ownable_id)
  217. ''')
  218. cursor.execute('''
  219. CREATE INDEX IF NOT EXISTS orders_expiry
  220. ON orders (expiry_dt)
  221. ''')
  222. cursor.execute('''
  223. CREATE INDEX IF NOT EXISTS orders_ownership
  224. ON orders (ownership_id)
  225. ''')
  226. cursor.execute('''
  227. CREATE INDEX IF NOT EXISTS transactions_dt
  228. ON transactions (dt)
  229. ''')
  230. cursor.execute('''
  231. CREATE INDEX IF NOT EXISTS news_dt
  232. ON news (dt)
  233. ''')
  234. cursor.execute('''
  235. CREATE INDEX IF NOT EXISTS ownables_name
  236. ON ownables (name)
  237. ''')
  238. cursor.execute('''
  239. CREATE INDEX IF NOT EXISTS users_name
  240. ON users (username)
  241. ''')
  242. cursor.execute('''
  243. CREATE INDEX IF NOT EXISTS sessions_id
  244. ON sessions (session_id)
  245. ''')
  246. cursor.execute('''
  247. CREATE INDEX IF NOT EXISTS sessions_user
  248. ON sessions (user_id)
  249. ''')
  250. def tables(cursor):
  251. print(' - Creating tables...')
  252. cursor.execute('''
  253. CREATE TABLE IF NOT EXISTS users(
  254. username VARCHAR(10) UNIQUE NOT NULL,
  255. password VARCHAR(200) NOT NULL)
  256. ''')
  257. cursor.execute('''
  258. CREATE TABLE IF NOT EXISTS ownables(
  259. name VARCHAR(10) UNIQUE NOT NULL)
  260. ''')
  261. cursor.execute('''
  262. CREATE TABLE IF NOT EXISTS ownership(
  263. user_id INTEGER NOT NULL,
  264. ownable_id INTEGER NOT NULL,
  265. amount CURRENCY NOT NULL DEFAULT 0,
  266. FOREIGN KEY (user_id) REFERENCES users(rowid),
  267. FOREIGN KEY (ownable_id) REFERENCES ownables(rowid),
  268. UNIQUE (user_id, ownable_id)
  269. )
  270. ''')
  271. cursor.execute('''
  272. CREATE TABLE IF NOT EXISTS sessions(
  273. user_id INTEGER NOT NULL,
  274. session_id STRING NOT NULL,
  275. FOREIGN KEY (user_id) REFERENCES users(rowid)
  276. )
  277. ''')
  278. cursor.execute('''
  279. CREATE TABLE IF NOT EXISTS orders(
  280. ownership_id INTEGER NOT NULL,
  281. buy BOOLEAN NOT NULL,
  282. "limit" CURRENCY,
  283. stop_loss BOOLEAN,
  284. ordered_amount CURRENCY NOT NULL,
  285. executed_amount CURRENCY DEFAULT 0 NOT NULL,
  286. expiry_dt DATETIME NOT NULL,
  287. FOREIGN KEY (ownership_id) REFERENCES ownership(rowid)
  288. )
  289. ''')
  290. cursor.execute('''
  291. CREATE TABLE IF NOT EXISTS transactions(
  292. dt DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
  293. price CURRENCY NOT NULL,
  294. ownable_id INTEGER NOT NULL,
  295. amount CURRENCY NOT NULL,
  296. FOREIGN KEY (ownable_id) REFERENCES ownable(rowid)
  297. )
  298. ''')
  299. cursor.execute('''
  300. CREATE TABLE IF NOT EXISTS keys(
  301. key STRING UNIQUE NOT NULL,
  302. used_by_user_id INTEGER,
  303. FOREIGN KEY (used_by_user_id) REFERENCES user(rowid)
  304. )
  305. ''')
  306. cursor.execute('''
  307. CREATE TABLE IF NOT EXISTS news(
  308. dt DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
  309. title VARCHAR(50) NOT NULL
  310. )
  311. ''')