1
1

db_setup.py 14 KB

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