1
1

db_setup.py 20 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444
  1. from sqlite3 import OperationalError
  2. from game import CURRENCY_NAME, MINIMUM_ORDER_AMOUNT
  3. def setup(cursor):
  4. print('Database setup...')
  5. drop_triggers(cursor)
  6. tables(cursor)
  7. create_triggers(cursor)
  8. create_indices(cursor)
  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. cursor.execute("DROP TRIGGER IF EXISTS not_nullify_buyer_id_after_update")
  37. cursor.execute("DROP TRIGGER IF EXISTS buyer_id_not_null_after_insert")
  38. cursor.execute("DROP TRIGGER IF EXISTS not_nullify_seller_id_after_update")
  39. cursor.execute("DROP TRIGGER IF EXISTS seller_id_not_null_after_insert")
  40. # def drop_database(cursor):
  41. # print(' - Dropping old tables...')
  42. # cursor.execute("DROP TABLE IF EXISTS users")
  43. # cursor.execute("DROP TABLE IF EXISTS ownables")
  44. # cursor.execute("DROP TABLE IF EXISTS ownership")
  45. # cursor.execute("DROP TABLE IF EXISTS sessions")
  46. # cursor.execute("DROP TABLE IF EXISTS orders")
  47. # cursor.execute("DROP TABLE IF EXISTS transactions")
  48. # cursor.execute("DROP TABLE IF EXISTS keys")
  49. # cursor.execute("DROP TABLE IF EXISTS news")
  50. def seed(cursor):
  51. print(' - Seeding initial data...')
  52. # ₭ollar
  53. cursor.execute('''
  54. INSERT OR IGNORE INTO ownables
  55. (name)
  56. VALUES (?)
  57. ''', (CURRENCY_NAME,))
  58. # The bank/external investors
  59. cursor.execute('''
  60. INSERT OR IGNORE INTO users
  61. (username,password)
  62. VALUES ('bank','')
  63. ''')
  64. # bank owns all the money that is not owned by players, 1000 * num_used_key - player_money
  65. cursor.execute('''
  66. INSERT OR IGNORE INTO ownership
  67. (user_id, ownable_id, amount)
  68. VALUES ((SELECT rowid FROM users WHERE username = 'bank'),
  69. (SELECT rowid FROM ownables WHERE name = ?),
  70. 1000 * (SELECT COUNT(used_by_user_id) FROM keys) - (SELECT SUM(amount)
  71. FROM ownership
  72. WHERE ownable_id = (SELECT rowid FROM ownables WHERE name = ?)))
  73. ''', (CURRENCY_NAME, CURRENCY_NAME,))
  74. # bank owns some stuff (₭ollar is be dealt with separately)
  75. cursor.execute('''
  76. INSERT OR IGNORE INTO ownership
  77. (user_id, ownable_id, amount)
  78. SELECT (SELECT rowid FROM users WHERE username = 'bank'),
  79. ownables.rowid,
  80. (SELECT SUM(amount) FROM ownership WHERE ownable_id = ownables.rowid)
  81. FROM ownables WHERE
  82. name <> ?
  83. ''', (CURRENCY_NAME,))
  84. def create_triggers(cursor):
  85. print(' - Creating triggers...')
  86. cursor.execute('''
  87. CREATE TRIGGER IF NOT EXISTS owned_amount_not_negative_after_insert
  88. AFTER INSERT ON ownership
  89. WHEN NEW.amount < 0
  90. BEGIN SELECT RAISE(ROLLBACK, 'Can not own an amount less than 0.'); END
  91. ''')
  92. cursor.execute('''
  93. CREATE TRIGGER IF NOT EXISTS owned_amount_not_negative_after_update
  94. AFTER UPDATE ON ownership
  95. WHEN NEW.amount < 0
  96. BEGIN SELECT RAISE(ROLLBACK, 'Can not own an amount less than 0.'); END
  97. ''')
  98. cursor.execute('''
  99. CREATE TRIGGER IF NOT EXISTS amount_positive_after_insert
  100. AFTER INSERT ON transactions
  101. WHEN NEW.amount <= 0
  102. BEGIN SELECT RAISE(ROLLBACK, 'Can not perform empty transactions.'); END
  103. ''')
  104. cursor.execute('''
  105. CREATE TRIGGER IF NOT EXISTS amount_positive_after_update
  106. AFTER UPDATE ON transactions
  107. WHEN NEW.amount <= 0
  108. BEGIN SELECT RAISE(ROLLBACK, 'Can not perform empty transactions.'); END
  109. ''')
  110. cursor.execute('''
  111. CREATE TRIGGER IF NOT EXISTS order_limit_not_negative_after_insert
  112. AFTER INSERT ON orders
  113. WHEN NEW."limit" IS NOT NULL AND NEW."limit" < 0
  114. BEGIN SELECT RAISE(ROLLBACK, 'Can not set a limit less than 0.'); END
  115. ''')
  116. cursor.execute('''
  117. CREATE TRIGGER IF NOT EXISTS order_limit_not_negative_after_update
  118. AFTER UPDATE ON orders
  119. WHEN NEW."limit" IS NOT NULL AND NEW."limit" < 0
  120. BEGIN SELECT RAISE(ROLLBACK, 'Can not set a limit less than 0.'); END
  121. ''')
  122. cursor.execute('''
  123. CREATE TRIGGER IF NOT EXISTS order_amount_positive_after_insert
  124. AFTER INSERT ON orders
  125. WHEN NEW.ordered_amount <= 0 OR NEW.executed_amount < 0
  126. BEGIN SELECT RAISE(ROLLBACK, 'Can not order 0 or less.'); END
  127. ''')
  128. cursor.execute('''
  129. CREATE TRIGGER IF NOT EXISTS order_amount_positive_after_update
  130. AFTER UPDATE ON orders
  131. WHEN NEW.ordered_amount <= 0 OR NEW.executed_amount < 0
  132. BEGIN SELECT RAISE(ROLLBACK, 'Can not order 0 or less.'); END
  133. ''')
  134. cursor.execute('''
  135. CREATE TRIGGER IF NOT EXISTS not_more_executed_than_ordered_after_insert
  136. AFTER INSERT ON orders
  137. WHEN NEW.ordered_amount < NEW.executed_amount
  138. BEGIN SELECT RAISE(ROLLBACK, 'Can not execute more than ordered.'); END
  139. ''')
  140. cursor.execute('''
  141. CREATE TRIGGER IF NOT EXISTS not_more_executed_than_ordered_after_update
  142. AFTER UPDATE ON orders
  143. WHEN NEW.ordered_amount < NEW.executed_amount
  144. BEGIN SELECT RAISE(ROLLBACK, 'Can not execute more than ordered.'); END
  145. ''')
  146. cursor.execute('''
  147. CREATE TRIGGER IF NOT EXISTS not_more_ordered_than_available_after_insert
  148. AFTER INSERT ON orders
  149. WHEN NOT NEW.buy AND 0 >
  150. -- owned_amount
  151. COALESCE (
  152. (SELECT amount
  153. FROM ownership
  154. WHERE ownership.rowid = NEW.ownership_id), 0)
  155. - -- sell_ordered_amount
  156. (SELECT COALESCE(SUM(orders.ordered_amount - orders.executed_amount),0)
  157. FROM orders, ownership
  158. WHERE ownership.rowid = orders.ownership_id
  159. AND ownership.rowid = NEW.ownership_id
  160. AND NOT orders.buy)
  161. BEGIN SELECT RAISE(ROLLBACK, 'Can not order more than you own.'); END
  162. ''')
  163. cursor.execute('''
  164. CREATE TRIGGER IF NOT EXISTS not_more_ordered_than_available_after_update
  165. AFTER UPDATE ON orders
  166. WHEN NOT NEW.buy AND 0 >
  167. -- owned_amount
  168. COALESCE (
  169. (SELECT amount
  170. FROM ownership
  171. WHERE ownership.rowid = NEW.ownership_id), 0)
  172. - -- sell_ordered_amount
  173. (SELECT COALESCE(SUM(orders.ordered_amount - orders.executed_amount),0)
  174. FROM orders, ownership
  175. WHERE ownership.rowid = orders.ownership_id
  176. AND ownership.rowid = NEW.ownership_id
  177. AND NOT orders.buy)
  178. BEGIN SELECT RAISE(ROLLBACK, 'Can not order more than you own.'); END
  179. ''')
  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_insert
  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. cursor.execute('''
  265. CREATE TRIGGER IF NOT EXISTS not_nullify_buyer_id_after_update
  266. AFTER UPDATE ON transactions
  267. WHEN NEW.buyer_id IS NULL AND OLD.buyer_id IS NOT NULL
  268. BEGIN SELECT RAISE(ROLLBACK, 'Cannot nullify buyer_id.'); END
  269. ''')
  270. cursor.execute('''
  271. CREATE TRIGGER IF NOT EXISTS buyer_id_not_null_after_insert
  272. AFTER INSERT ON transactions
  273. WHEN NEW.buyer_id IS NULL
  274. BEGIN SELECT RAISE(ROLLBACK, 'buyer_id must not be null for new transactions.'); END
  275. ''')
  276. cursor.execute('''
  277. CREATE TRIGGER IF NOT EXISTS not_nullify_seller_id_after_update
  278. AFTER UPDATE ON transactions
  279. WHEN NEW.seller_id IS NULL AND OLD.seller_id IS NOT NULL
  280. BEGIN SELECT RAISE(ROLLBACK, 'Cannot nullify seller_id.'); END
  281. ''')
  282. cursor.execute('''
  283. CREATE TRIGGER IF NOT EXISTS seller_id_not_null_after_insert
  284. AFTER INSERT ON transactions
  285. WHEN NEW.seller_id IS NULL
  286. BEGIN SELECT RAISE(ROLLBACK, 'seller_id must not be null for new transactions.'); END
  287. ''')
  288. def create_indices(cursor):
  289. print(' - Creating indices...')
  290. cursor.execute('''
  291. CREATE INDEX IF NOT EXISTS ownership_ownable
  292. ON ownership (ownable_id)
  293. ''')
  294. cursor.execute('''
  295. CREATE INDEX IF NOT EXISTS transactions_ownable
  296. ON transactions (ownable_id)
  297. ''')
  298. cursor.execute('''
  299. CREATE INDEX IF NOT EXISTS orders_expiry
  300. ON orders (expiry_dt)
  301. ''')
  302. cursor.execute('''
  303. CREATE INDEX IF NOT EXISTS orders_ownership
  304. ON orders (ownership_id)
  305. ''')
  306. cursor.execute('''
  307. CREATE INDEX IF NOT EXISTS orders_limit
  308. ON orders ("limit")
  309. ''')
  310. cursor.execute('''
  311. CREATE INDEX IF NOT EXISTS transactions_dt
  312. ON transactions (dt)
  313. ''')
  314. cursor.execute('''
  315. CREATE INDEX IF NOT EXISTS news_dt
  316. ON news (dt)
  317. ''')
  318. cursor.execute('''
  319. CREATE INDEX IF NOT EXISTS ownables_name
  320. ON ownables (name)
  321. ''')
  322. cursor.execute('''
  323. CREATE INDEX IF NOT EXISTS users_name
  324. ON users (username)
  325. ''')
  326. cursor.execute('''
  327. CREATE INDEX IF NOT EXISTS sessions_id
  328. ON sessions (session_id)
  329. ''')
  330. cursor.execute('''
  331. CREATE INDEX IF NOT EXISTS sessions_user
  332. ON sessions (user_id)
  333. ''')
  334. cursor.execute('''
  335. CREATE INDEX IF NOT EXISTS transactions_seller
  336. ON transactions (seller_id)
  337. ''')
  338. cursor.execute('''
  339. CREATE INDEX IF NOT EXISTS transactions_buyer
  340. ON transactions (buyer_id)
  341. ''')
  342. def tables(cursor):
  343. print(' - Creating tables...')
  344. cursor.execute('''
  345. CREATE TABLE IF NOT EXISTS users(
  346. username VARCHAR(10) UNIQUE NOT NULL,
  347. password VARCHAR(200) NOT NULL)
  348. ''')
  349. cursor.execute('''
  350. CREATE TABLE IF NOT EXISTS ownables(
  351. name VARCHAR(10) UNIQUE NOT NULL)
  352. ''')
  353. cursor.execute('''
  354. CREATE TABLE IF NOT EXISTS ownership(
  355. user_id INTEGER NOT NULL,
  356. ownable_id INTEGER NOT NULL,
  357. amount CURRENCY NOT NULL DEFAULT 0,
  358. FOREIGN KEY (user_id) REFERENCES users(rowid),
  359. FOREIGN KEY (ownable_id) REFERENCES ownables(rowid),
  360. UNIQUE (user_id, ownable_id)
  361. )
  362. ''')
  363. cursor.execute('''
  364. CREATE TABLE IF NOT EXISTS sessions(
  365. user_id INTEGER NOT NULL,
  366. session_id STRING NOT NULL,
  367. FOREIGN KEY (user_id) REFERENCES users(rowid)
  368. )
  369. ''')
  370. cursor.execute('''
  371. CREATE TABLE IF NOT EXISTS orders(
  372. ownership_id INTEGER NOT NULL,
  373. buy BOOLEAN NOT NULL,
  374. "limit" CURRENCY,
  375. stop_loss BOOLEAN,
  376. ordered_amount CURRENCY NOT NULL,
  377. executed_amount CURRENCY DEFAULT 0 NOT NULL,
  378. expiry_dt DATETIME NOT NULL,
  379. FOREIGN KEY (ownership_id) REFERENCES ownership(rowid)
  380. )
  381. ''')
  382. cursor.execute('''
  383. CREATE TABLE IF NOT EXISTS transactions(
  384. dt DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
  385. price CURRENCY NOT NULL,
  386. ownable_id INTEGER NOT NULL,
  387. amount CURRENCY NOT NULL,
  388. FOREIGN KEY (ownable_id) REFERENCES ownable(rowid)
  389. )
  390. ''')
  391. _add_column_if_not_exists(cursor, '''
  392. -- there is a not null constraint for new values that is watched by triggers
  393. ALTER TABLE transactions ADD COLUMN buyer_id INTEGER REFERENCES user(rowid)
  394. ''')
  395. _add_column_if_not_exists(cursor, '''
  396. -- there is a not null constraint for new values that is watched by triggers
  397. ALTER TABLE transactions ADD COLUMN seller_id INTEGER REFERENCES user(rowid)
  398. ''')
  399. cursor.execute('''
  400. CREATE TABLE IF NOT EXISTS keys(
  401. key STRING UNIQUE NOT NULL,
  402. used_by_user_id INTEGER,
  403. FOREIGN KEY (used_by_user_id) REFERENCES user(rowid)
  404. )
  405. ''')
  406. cursor.execute('''
  407. CREATE TABLE IF NOT EXISTS news(
  408. dt DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
  409. title VARCHAR(50) NOT NULL
  410. )
  411. ''')
  412. def _add_column_if_not_exists(cursor, query):
  413. if 'ALTER TABLE' not in query:
  414. raise ValueError('Only alter table queries allowed.')
  415. if 'ADD COLUMN' not in query:
  416. raise ValueError('Only add column queries allowed.')
  417. try:
  418. cursor.execute(query)
  419. except OperationalError as e: # if the column already exists this will happen
  420. if 'duplicate column name' not in e.args[0]:
  421. raise