db_setup.py 15 KB

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