db_setup.py 11 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244
  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. if seed_tables:
  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. # def drop_database(cursor):
  30. # print(' - Dropping old tables...')
  31. # cursor.execute("DROP TABLE IF EXISTS users")
  32. # cursor.execute("DROP TABLE IF EXISTS ownables")
  33. # cursor.execute("DROP TABLE IF EXISTS ownership")
  34. # cursor.execute("DROP TABLE IF EXISTS sessions")
  35. # cursor.execute("DROP TABLE IF EXISTS orders")
  36. # cursor.execute("DROP TABLE IF EXISTS transactions")
  37. # cursor.execute("DROP TABLE IF EXISTS keys")
  38. # cursor.execute("DROP TABLE IF EXISTS news")
  39. def seed(cursor):
  40. print(' - Seeding initial data...')
  41. cursor.execute('''
  42. INSERT INTO ownables
  43. (name)
  44. VALUES (?)
  45. ''', (CURRENCY_NAME,))
  46. cursor.execute('''
  47. INSERT INTO users
  48. (username,password)
  49. VALUES ('bank','')
  50. ''')
  51. cursor.execute('''
  52. INSERT INTO ownership
  53. (user_id, ownable_id)
  54. VALUES ((SELECT rowid FROM users WHERE username = 'bank'),
  55. (SELECT rowid FROM ownables WHERE name = ?))
  56. ''', (CURRENCY_NAME,))
  57. def create_triggers(cursor):
  58. print(' - Creating triggers...')
  59. cursor.execute('''
  60. CREATE TRIGGER IF NOT EXISTS owned_amount_not_negative_after_insert
  61. AFTER INSERT ON ownership
  62. WHEN NEW.amount < 0
  63. BEGIN SELECT RAISE(ROLLBACK, 'Can not own an amount less than 0.'); END
  64. ''')
  65. cursor.execute('''
  66. CREATE TRIGGER IF NOT EXISTS owned_amount_not_negative_after_update
  67. AFTER UPDATE ON ownership
  68. WHEN NEW.amount < 0
  69. BEGIN SELECT RAISE(ROLLBACK, 'Can not own an amount less than 0.'); END
  70. ''')
  71. cursor.execute('''
  72. CREATE TRIGGER IF NOT EXISTS amount_positive_after_insert
  73. AFTER INSERT ON transactions
  74. WHEN NEW.amount <= 0
  75. BEGIN SELECT RAISE(ROLLBACK, 'Can not perform empty transactions.'); END
  76. ''')
  77. cursor.execute('''
  78. CREATE TRIGGER IF NOT EXISTS amount_positive_after_update
  79. AFTER UPDATE ON transactions
  80. WHEN NEW.amount <= 0
  81. BEGIN SELECT RAISE(ROLLBACK, 'Can not perform empty transactions.'); END
  82. ''')
  83. cursor.execute('''
  84. CREATE TRIGGER IF NOT EXISTS order_limit_not_negative_after_insert
  85. AFTER INSERT ON orders
  86. WHEN NEW."limit" IS NOT NULL AND NEW."limit" < 0
  87. BEGIN SELECT RAISE(ROLLBACK, 'Can not set a limit less than 0.'); END
  88. ''')
  89. cursor.execute('''
  90. CREATE TRIGGER IF NOT EXISTS order_limit_not_negative_after_update
  91. AFTER UPDATE ON orders
  92. WHEN NEW."limit" IS NOT NULL AND NEW."limit" < 0
  93. BEGIN SELECT RAISE(ROLLBACK, 'Can not set a limit less than 0.'); END
  94. ''')
  95. cursor.execute('''
  96. CREATE TRIGGER IF NOT EXISTS order_amount_positive_after_insert
  97. AFTER INSERT ON orders
  98. WHEN NEW.ordered_amount <= 0 OR NEW.executed_amount < 0
  99. BEGIN SELECT RAISE(ROLLBACK, 'Can not order 0 or less.'); END
  100. ''')
  101. cursor.execute('''
  102. CREATE TRIGGER IF NOT EXISTS order_amount_positive_after_update
  103. AFTER UPDATE ON orders
  104. WHEN NEW.ordered_amount <= 0 OR NEW.executed_amount < 0
  105. BEGIN SELECT RAISE(ROLLBACK, 'Can not order 0 or less.'); END
  106. ''')
  107. cursor.execute('''
  108. CREATE TRIGGER IF NOT EXISTS not_more_executed_than_ordered_after_insert
  109. AFTER INSERT ON orders
  110. WHEN NEW.ordered_amount < NEW.executed_amount
  111. BEGIN SELECT RAISE(ROLLBACK, 'Can not execute more than ordered.'); END
  112. ''')
  113. cursor.execute('''
  114. CREATE TRIGGER IF NOT EXISTS not_more_executed_than_ordered_after_update
  115. AFTER UPDATE ON orders
  116. WHEN NEW.ordered_amount < NEW.executed_amount
  117. BEGIN SELECT RAISE(ROLLBACK, 'Can not execute more than ordered.'); END
  118. ''')
  119. cursor.execute('''
  120. CREATE TRIGGER IF NOT EXISTS expiry_dt_in_future_after_insert
  121. AFTER INSERT ON orders
  122. WHEN NEW.expiry_dt <= datetime('now')
  123. BEGIN SELECT RAISE(ROLLBACK, 'Order is already expired.'); END
  124. ''')
  125. cursor.execute('''
  126. CREATE TRIGGER IF NOT EXISTS expiry_dt_in_future_after_update
  127. AFTER UPDATE ON orders
  128. WHEN NEW.expiry_dt <= datetime('now')
  129. BEGIN SELECT RAISE(ROLLBACK, 'Order is already expired.'); END
  130. ''')
  131. cursor.execute('''
  132. CREATE TRIGGER IF NOT EXISTS stop_loss_requires_limit_after_insert
  133. AFTER INSERT ON orders
  134. WHEN NEW."limit" IS NULL AND NEW.stop_loss IS NOT NULL
  135. BEGIN SELECT RAISE(ROLLBACK, 'Can only set `stop_loss` `for limit orders.'); END
  136. ''')
  137. cursor.execute('''
  138. CREATE TRIGGER IF NOT EXISTS stop_loss_requires_limit_after_update
  139. AFTER UPDATE ON orders
  140. WHEN NEW."limit" IS NULL AND NEW.stop_loss IS NOT NULL
  141. BEGIN SELECT RAISE(ROLLBACK, 'Can only set `stop_loss` `for limit orders.'); END
  142. ''')
  143. cursor.execute('''
  144. CREATE TRIGGER IF NOT EXISTS limit_requires_stop_loss_after_insert
  145. AFTER INSERT ON orders
  146. WHEN NEW."limit" IS NOT NULL AND NEW.stop_loss IS NULL
  147. BEGIN SELECT RAISE(ROLLBACK, 'Need to set stop_loss to either True or False for limit orders.'); END
  148. ''')
  149. cursor.execute('''
  150. CREATE TRIGGER IF NOT EXISTS limit_requires_stop_loss_after_update
  151. AFTER UPDATE ON orders
  152. WHEN NEW."limit" IS NOT NULL AND NEW.stop_loss IS NULL
  153. BEGIN SELECT RAISE(ROLLBACK, 'Need to set stop_loss to either True or False for limit orders.'); END
  154. ''')
  155. cursor.execute('''
  156. CREATE TRIGGER IF NOT EXISTS minimum_order_amount_after_insert
  157. AFTER INSERT ON orders
  158. WHEN NEW.ordered_amount < ?
  159. BEGIN SELECT RAISE(ROLLBACK, 'There is a minimum amount for new orders.'); END
  160. '''.replace('?',str(MINIMUM_ORDER_AMOUNT)))
  161. cursor.execute('''
  162. CREATE TRIGGER IF NOT EXISTS integer_amount_after_insert
  163. AFTER INSERT ON orders
  164. WHEN NEW.ordered_amount <> ROUND(NEW.ordered_amount)
  165. BEGIN SELECT RAISE(ROLLBACK, 'Can only set integer amounts for new orders.'); END
  166. '''.replace('?',str(MINIMUM_ORDER_AMOUNT)))
  167. def tables(cursor):
  168. print(' - Creating tables...')
  169. cursor.execute('''
  170. CREATE TABLE IF NOT EXISTS users(
  171. username VARCHAR(10) UNIQUE NOT NULL,
  172. password VARCHAR(200) NOT NULL)
  173. ''')
  174. cursor.execute('''
  175. CREATE TABLE IF NOT EXISTS ownables(
  176. name VARCHAR(10) UNIQUE NOT NULL)
  177. ''')
  178. cursor.execute('''
  179. CREATE TABLE IF NOT EXISTS ownership(
  180. user_id INTEGER NOT NULL,
  181. ownable_id INTEGER NOT NULL,
  182. amount CURRENCY NOT NULL DEFAULT 0,
  183. FOREIGN KEY (user_id) REFERENCES users(rowid),
  184. FOREIGN KEY (ownable_id) REFERENCES ownables(rowid),
  185. UNIQUE (user_id, ownable_id)
  186. )
  187. ''')
  188. cursor.execute('''
  189. CREATE TABLE IF NOT EXISTS sessions(
  190. user_id INTEGER NOT NULL,
  191. session_id STRING NOT NULL,
  192. FOREIGN KEY (user_id) REFERENCES users(rowid)
  193. )
  194. ''')
  195. cursor.execute('''
  196. CREATE TABLE IF NOT EXISTS orders(
  197. ownership_id INTEGER NOT NULL,
  198. buy BOOLEAN NOT NULL,
  199. "limit" CURRENCY,
  200. stop_loss BOOLEAN,
  201. ordered_amount CURRENCY NOT NULL,
  202. executed_amount CURRENCY DEFAULT 0 NOT NULL,
  203. expiry_dt DATETIME NOT NULL,
  204. FOREIGN KEY (ownership_id) REFERENCES ownership(rowid)
  205. )
  206. ''')
  207. cursor.execute('''
  208. CREATE TABLE IF NOT EXISTS transactions(
  209. dt DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
  210. price CURRENCY NOT NULL,
  211. ownable_id INTEGER NOT NULL,
  212. amount CURRENCY NOT NULL,
  213. FOREIGN KEY (ownable_id) REFERENCES ownable(rowid)
  214. )
  215. ''')
  216. cursor.execute('''
  217. CREATE TABLE IF NOT EXISTS keys(
  218. key STRING UNIQUE NOT NULL,
  219. used_by_user_id INTEGER,
  220. FOREIGN KEY (used_by_user_id) REFERENCES user(rowid)
  221. )
  222. ''')
  223. cursor.execute('''
  224. CREATE TABLE IF NOT EXISTS news(
  225. dt DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
  226. title VARCHAR(50) NOT NULL
  227. )
  228. ''')