db_setup.py 18 KB

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