1
1

db_setup.py 18 KB

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