db_setup.py 21 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465
  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 seed(cursor):
  41. print(' - Seeding initial data...')
  42. # ₭ollar
  43. cursor.execute('''
  44. INSERT OR IGNORE INTO ownables
  45. (name)
  46. VALUES (?)
  47. ''', (CURRENCY_NAME,))
  48. # The bank/external investors
  49. cursor.execute('''
  50. INSERT OR IGNORE INTO users
  51. (username,password)
  52. VALUES ('bank','')
  53. ''')
  54. # bank owns all the money that is not owned by players, 1000 * num_used_key - player_money
  55. cursor.execute('''
  56. INSERT OR IGNORE INTO ownership
  57. (user_id, ownable_id, amount)
  58. VALUES ((SELECT rowid FROM users WHERE username = 'bank'),
  59. (SELECT rowid FROM ownables WHERE name = ?),
  60. 1000 * (SELECT COUNT(used_by_user_id) FROM keys) - (SELECT SUM(amount)
  61. FROM ownership
  62. WHERE ownable_id = (SELECT rowid FROM ownables WHERE name = ?)))
  63. ''', (CURRENCY_NAME, CURRENCY_NAME,))
  64. # bank owns some stuff (₭ollar is be dealt with separately)
  65. cursor.execute('''
  66. INSERT OR IGNORE INTO ownership
  67. (user_id, ownable_id, amount)
  68. SELECT (SELECT rowid FROM users WHERE username = 'bank'),
  69. ownables.rowid,
  70. (SELECT SUM(amount) FROM ownership WHERE ownable_id = ownables.rowid)
  71. FROM ownables WHERE
  72. name <> ?
  73. ''', (CURRENCY_NAME,))
  74. def create_triggers(cursor):
  75. print(' - Creating triggers...')
  76. cursor.execute('''
  77. CREATE TRIGGER IF NOT EXISTS owned_amount_not_negative_after_insert
  78. AFTER INSERT ON ownership
  79. WHEN NEW.amount < 0
  80. BEGIN SELECT RAISE(ROLLBACK, 'Can not own an amount less than 0.'); END
  81. ''')
  82. cursor.execute('''
  83. CREATE TRIGGER IF NOT EXISTS owned_amount_not_negative_after_update
  84. AFTER UPDATE ON ownership
  85. WHEN NEW.amount < 0
  86. BEGIN SELECT RAISE(ROLLBACK, 'Can not own an amount less than 0.'); END
  87. ''')
  88. cursor.execute('''
  89. CREATE TRIGGER IF NOT EXISTS amount_positive_after_insert
  90. AFTER INSERT ON transactions
  91. WHEN NEW.amount <= 0
  92. BEGIN SELECT RAISE(ROLLBACK, 'Can not perform empty transactions.'); END
  93. ''')
  94. cursor.execute('''
  95. CREATE TRIGGER IF NOT EXISTS amount_positive_after_update
  96. AFTER UPDATE ON transactions
  97. WHEN NEW.amount <= 0
  98. BEGIN SELECT RAISE(ROLLBACK, 'Can not perform empty transactions.'); END
  99. ''')
  100. cursor.execute('''
  101. CREATE TRIGGER IF NOT EXISTS order_limit_not_negative_after_insert
  102. AFTER INSERT ON orders
  103. WHEN NEW."limit" IS NOT NULL AND NEW."limit" < 0
  104. BEGIN SELECT RAISE(ROLLBACK, 'Can not set a limit less than 0.'); END
  105. ''')
  106. cursor.execute('''
  107. CREATE TRIGGER IF NOT EXISTS order_limit_not_negative_after_update
  108. AFTER UPDATE ON orders
  109. WHEN NEW."limit" IS NOT NULL AND NEW."limit" < 0
  110. BEGIN SELECT RAISE(ROLLBACK, 'Can not set a limit less than 0.'); END
  111. ''')
  112. cursor.execute('''
  113. CREATE TRIGGER IF NOT EXISTS order_amount_positive_after_insert
  114. AFTER INSERT ON orders
  115. WHEN NEW.ordered_amount <= 0 OR NEW.executed_amount < 0
  116. BEGIN SELECT RAISE(ROLLBACK, 'Can not order 0 or less.'); END
  117. ''')
  118. cursor.execute('''
  119. CREATE TRIGGER IF NOT EXISTS order_amount_positive_after_update
  120. AFTER UPDATE ON orders
  121. WHEN NEW.ordered_amount <= 0 OR NEW.executed_amount < 0
  122. BEGIN SELECT RAISE(ROLLBACK, 'Can not order 0 or less.'); END
  123. ''')
  124. cursor.execute('''
  125. CREATE TRIGGER IF NOT EXISTS not_more_executed_than_ordered_after_insert
  126. AFTER INSERT ON orders
  127. WHEN NEW.ordered_amount < NEW.executed_amount
  128. BEGIN SELECT RAISE(ROLLBACK, 'Can not execute more than ordered.'); END
  129. ''')
  130. cursor.execute('''
  131. CREATE TRIGGER IF NOT EXISTS not_more_executed_than_ordered_after_update
  132. AFTER UPDATE ON orders
  133. WHEN NEW.ordered_amount < NEW.executed_amount
  134. BEGIN SELECT RAISE(ROLLBACK, 'Can not execute more than ordered.'); END
  135. ''')
  136. cursor.execute('''
  137. CREATE TRIGGER IF NOT EXISTS not_more_ordered_than_available_after_insert
  138. AFTER INSERT ON orders
  139. WHEN NOT NEW.buy AND 0 >
  140. -- owned_amount
  141. COALESCE (
  142. (SELECT amount
  143. FROM ownership
  144. WHERE ownership.rowid = NEW.ownership_id), 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. BEGIN SELECT RAISE(ROLLBACK, 'Can not order more than you own.'); END
  152. ''')
  153. cursor.execute('''
  154. CREATE TRIGGER IF NOT EXISTS not_more_ordered_than_available_after_update
  155. AFTER UPDATE ON orders
  156. WHEN NOT NEW.buy AND 0 >
  157. -- owned_amount
  158. COALESCE (
  159. (SELECT amount
  160. FROM ownership
  161. WHERE ownership.rowid = NEW.ownership_id), 0)
  162. - -- sell_ordered_amount
  163. (SELECT COALESCE(SUM(orders.ordered_amount - orders.executed_amount),0)
  164. FROM orders, ownership
  165. WHERE ownership.rowid = orders.ownership_id
  166. AND ownership.rowid = NEW.ownership_id
  167. AND NOT orders.buy)
  168. BEGIN SELECT RAISE(ROLLBACK, 'Can not order more than you own.'); END
  169. ''')
  170. cursor.execute('''
  171. CREATE TRIGGER IF NOT EXISTS expiry_dt_in_future_after_insert
  172. AFTER INSERT ON orders
  173. WHEN NEW.expiry_dt <= datetime('now')
  174. BEGIN SELECT RAISE(ROLLBACK, 'Order is already expired.'); END
  175. ''')
  176. cursor.execute('''
  177. CREATE TRIGGER IF NOT EXISTS expiry_dt_in_future_after_update
  178. AFTER UPDATE ON orders
  179. WHEN NEW.expiry_dt <= datetime('now')
  180. BEGIN SELECT RAISE(ROLLBACK, 'Order is already expired.'); END
  181. ''')
  182. cursor.execute('''
  183. CREATE TRIGGER IF NOT EXISTS stop_loss_requires_limit_after_insert
  184. AFTER INSERT ON orders
  185. WHEN NEW."limit" IS NULL AND NEW.stop_loss IS NOT NULL
  186. BEGIN SELECT RAISE(ROLLBACK, 'Can only set `stop_loss` `for limit orders.'); END
  187. ''')
  188. cursor.execute('''
  189. CREATE TRIGGER IF NOT EXISTS stop_loss_requires_limit_after_update
  190. AFTER UPDATE ON orders
  191. WHEN NEW."limit" IS NULL AND NEW.stop_loss IS NOT NULL
  192. BEGIN SELECT RAISE(ROLLBACK, 'Can only set `stop_loss` `for limit orders.'); END
  193. ''')
  194. cursor.execute('''
  195. CREATE TRIGGER IF NOT EXISTS limit_requires_stop_loss_after_insert
  196. AFTER INSERT ON orders
  197. WHEN NEW."limit" IS NOT NULL AND NEW.stop_loss IS NULL
  198. BEGIN SELECT RAISE(ROLLBACK, 'Need to set stop_loss to either True or False for limit orders.'); END
  199. ''')
  200. cursor.execute('''
  201. CREATE TRIGGER IF NOT EXISTS limit_requires_stop_loss_after_update
  202. AFTER UPDATE ON orders
  203. WHEN NEW."limit" IS NOT NULL AND NEW.stop_loss IS NULL
  204. BEGIN SELECT RAISE(ROLLBACK, 'Need to set stop_loss to either True or False for limit orders.'); END
  205. ''')
  206. cursor.execute('''
  207. CREATE TRIGGER IF NOT EXISTS minimum_order_amount_after_insert
  208. AFTER INSERT ON orders
  209. WHEN NEW.ordered_amount < ?
  210. BEGIN SELECT RAISE(ROLLBACK, 'There is a minimum amount for new orders.'); END
  211. '''.replace('?', str(MINIMUM_ORDER_AMOUNT)))
  212. cursor.execute('''
  213. CREATE TRIGGER IF NOT EXISTS integer_amount_after_insert
  214. AFTER INSERT ON orders
  215. WHEN NEW.ordered_amount <> ROUND(NEW.ordered_amount)
  216. BEGIN SELECT RAISE(ROLLBACK, 'Can only set integer amounts for new orders.'); END
  217. '''.replace('?', str(MINIMUM_ORDER_AMOUNT)))
  218. cursor.execute('''
  219. CREATE TRIGGER IF NOT EXISTS dt_monotonic_after_insert
  220. AFTER INSERT ON transactions
  221. WHEN NEW.dt < (SELECT MAX(dt) FROM transactions t2 WHERE t2.rowid < rowid)
  222. BEGIN SELECT RAISE(ROLLBACK, 'Transaction rowid programming bug, not your fault.'); END
  223. ''')
  224. cursor.execute('''
  225. CREATE TRIGGER IF NOT EXISTS dt_monotonic_after_update
  226. AFTER INSERT ON transactions
  227. WHEN NEW.dt < (SELECT MAX(dt) FROM transactions t2 WHERE t2.rowid < rowid)
  228. BEGIN SELECT RAISE(ROLLBACK, 'Transaction rowid programming bug, not your fault.'); END
  229. ''')
  230. cursor.execute('''
  231. CREATE TRIGGER IF NOT EXISTS news_dt_monotonic_after_insert
  232. AFTER INSERT ON news
  233. WHEN NEW.dt < (SELECT MAX(dt) FROM news t2 WHERE t2.rowid < rowid)
  234. BEGIN SELECT RAISE(ROLLBACK, 'Transaction rowid programming bug, not your fault.'); END
  235. ''')
  236. cursor.execute('''
  237. CREATE TRIGGER IF NOT EXISTS news_dt_monotonic_after_insert
  238. AFTER INSERT ON news
  239. WHEN NEW.dt < (SELECT MAX(dt) FROM news t2 WHERE t2.rowid < rowid)
  240. BEGIN SELECT RAISE(ROLLBACK, 'Transaction rowid programming bug, not your fault.'); END
  241. ''')
  242. cursor.execute('''
  243. CREATE TRIGGER IF NOT EXISTS orders_rowid_sorted_by_creation_time_after_insert
  244. AFTER INSERT ON orders
  245. WHEN NEW.rowid < (SELECT MAX(rowid) FROM orders o2)
  246. BEGIN SELECT RAISE(ROLLBACK, 'Order-rowid programming bug (insert), not your fault.'); END
  247. ''')
  248. cursor.execute('''
  249. CREATE TRIGGER IF NOT EXISTS news_dt_monotonic_after_update
  250. AFTER UPDATE ON orders
  251. WHEN NEW.rowid <> OLD.rowid
  252. BEGIN SELECT RAISE(ROLLBACK, 'Cannot change number of existing order.'); END
  253. ''')
  254. cursor.execute('''
  255. CREATE TRIGGER IF NOT EXISTS not_nullify_buyer_id_after_update
  256. AFTER UPDATE ON transactions
  257. WHEN NEW.buyer_id IS NULL AND OLD.buyer_id IS NOT NULL
  258. BEGIN SELECT RAISE(ROLLBACK, 'Cannot nullify buyer_id.'); END
  259. ''')
  260. cursor.execute('''
  261. CREATE TRIGGER IF NOT EXISTS buyer_id_not_null_after_insert
  262. AFTER INSERT ON transactions
  263. WHEN NEW.buyer_id IS NULL
  264. BEGIN SELECT RAISE(ROLLBACK, 'buyer_id must not be null for new transactions.'); END
  265. ''')
  266. cursor.execute('''
  267. CREATE TRIGGER IF NOT EXISTS not_nullify_seller_id_after_update
  268. AFTER UPDATE ON transactions
  269. WHEN NEW.seller_id IS NULL AND OLD.seller_id IS NOT NULL
  270. BEGIN SELECT RAISE(ROLLBACK, 'Cannot nullify seller_id.'); END
  271. ''')
  272. cursor.execute('''
  273. CREATE TRIGGER IF NOT EXISTS seller_id_not_null_after_insert
  274. AFTER INSERT ON transactions
  275. WHEN NEW.seller_id IS NULL
  276. BEGIN SELECT RAISE(ROLLBACK, 'seller_id must not be null for new transactions.'); END
  277. ''')
  278. cursor.execute('''
  279. CREATE TRIGGER IF NOT EXISTS order_history_no_update
  280. BEFORE UPDATE ON order_history
  281. BEGIN SELECT RAISE(ROLLBACK, 'Can not change order history.'); END
  282. ''')
  283. def create_indices(cursor):
  284. print(' - Creating indices...')
  285. cursor.execute('''
  286. CREATE INDEX IF NOT EXISTS ownership_ownable
  287. ON ownership (ownable_id)
  288. ''')
  289. cursor.execute('''
  290. CREATE INDEX IF NOT EXISTS transactions_ownable
  291. ON transactions (ownable_id)
  292. ''')
  293. cursor.execute('''
  294. CREATE INDEX IF NOT EXISTS orders_expiry
  295. ON orders (expiry_dt)
  296. ''')
  297. cursor.execute('''
  298. CREATE INDEX IF NOT EXISTS orders_ownership
  299. ON orders (ownership_id)
  300. ''')
  301. cursor.execute('''
  302. CREATE INDEX IF NOT EXISTS orders_limit
  303. ON orders ("limit")
  304. ''')
  305. cursor.execute('''
  306. CREATE INDEX IF NOT EXISTS transactions_dt
  307. ON transactions (dt)
  308. ''')
  309. cursor.execute('''
  310. CREATE INDEX IF NOT EXISTS news_dt
  311. ON news (dt)
  312. ''')
  313. cursor.execute('''
  314. CREATE INDEX IF NOT EXISTS ownables_name
  315. ON ownables (name)
  316. ''')
  317. cursor.execute('''
  318. CREATE INDEX IF NOT EXISTS users_name
  319. ON users (username)
  320. ''')
  321. cursor.execute('''
  322. CREATE INDEX IF NOT EXISTS sessions_id
  323. ON sessions (session_id)
  324. ''')
  325. cursor.execute('''
  326. CREATE INDEX IF NOT EXISTS sessions_user
  327. ON sessions (user_id)
  328. ''')
  329. cursor.execute('''
  330. CREATE INDEX IF NOT EXISTS transactions_seller
  331. ON transactions (seller_id)
  332. ''')
  333. cursor.execute('''
  334. CREATE INDEX IF NOT EXISTS transactions_buyer
  335. ON transactions (buyer_id)
  336. ''')
  337. cursor.execute('''
  338. CREATE INDEX IF NOT EXISTS order_history_id
  339. ON order_history (order_id)
  340. ''')
  341. cursor.execute('''
  342. CREATE INDEX IF NOT EXISTS order_canceled
  343. ON order_history (archived_dt)
  344. ''')
  345. cursor.execute('''
  346. CREATE INDEX IF NOT EXISTS order_history_ownership
  347. ON order_history (ownership_id)
  348. ''')
  349. def tables(cursor):
  350. print(' - Creating tables...')
  351. cursor.execute('''
  352. CREATE TABLE IF NOT EXISTS users(
  353. username VARCHAR(10) UNIQUE NOT NULL,
  354. password VARCHAR(200) NOT NULL)
  355. ''')
  356. cursor.execute('''
  357. CREATE TABLE IF NOT EXISTS ownables(
  358. name VARCHAR(10) UNIQUE NOT NULL)
  359. ''')
  360. cursor.execute('''
  361. CREATE TABLE IF NOT EXISTS ownership(
  362. user_id INTEGER NOT NULL,
  363. ownable_id INTEGER NOT NULL,
  364. amount CURRENCY NOT NULL DEFAULT 0,
  365. FOREIGN KEY (user_id) REFERENCES users(rowid),
  366. FOREIGN KEY (ownable_id) REFERENCES ownables(rowid),
  367. UNIQUE (user_id, ownable_id)
  368. )
  369. ''')
  370. cursor.execute('''
  371. CREATE TABLE IF NOT EXISTS sessions(
  372. user_id INTEGER NOT NULL,
  373. session_id STRING NOT NULL,
  374. FOREIGN KEY (user_id) REFERENCES users(rowid)
  375. )
  376. ''')
  377. cursor.execute('''
  378. CREATE TABLE IF NOT EXISTS orders(
  379. ownership_id INTEGER NOT NULL,
  380. buy BOOLEAN NOT NULL,
  381. "limit" CURRENCY,
  382. stop_loss BOOLEAN,
  383. ordered_amount CURRENCY NOT NULL,
  384. executed_amount CURRENCY DEFAULT 0 NOT NULL,
  385. expiry_dt DATETIME NOT NULL,
  386. FOREIGN KEY (ownership_id) REFERENCES ownership(rowid)
  387. )
  388. ''')
  389. cursor.execute('''
  390. CREATE TABLE IF NOT EXISTS order_history(
  391. ownership_id INTEGER NOT NULL,
  392. buy BOOLEAN NOT NULL,
  393. "limit" CURRENCY,
  394. ordered_amount CURRENCY NOT NULL,
  395. executed_amount CURRENCY NOT NULL,
  396. expiry_dt DATETIME NOT NULL,
  397. status VARCHAR(20) NOT NULL,
  398. order_id INTEGER NOT NULL,
  399. archived_dt DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
  400. FOREIGN KEY (ownership_id) REFERENCES ownership(rowid)
  401. -- order_id is not a FOREIGN KEY since orders are deleted from order table afterwards
  402. )
  403. ''')
  404. cursor.execute('''
  405. CREATE TABLE IF NOT EXISTS transactions(
  406. dt DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
  407. price CURRENCY NOT NULL,
  408. ownable_id INTEGER NOT NULL,
  409. amount CURRENCY NOT NULL,
  410. FOREIGN KEY (ownable_id) REFERENCES ownable(rowid)
  411. )
  412. ''')
  413. _add_column_if_not_exists(cursor, '''
  414. -- there is a not null constraint for new values that is watched by triggers
  415. ALTER TABLE transactions ADD COLUMN buyer_id INTEGER REFERENCES user(rowid)
  416. ''')
  417. _add_column_if_not_exists(cursor, '''
  418. -- there is a not null constraint for new values that is watched by triggers
  419. ALTER TABLE transactions ADD COLUMN seller_id INTEGER REFERENCES user(rowid)
  420. ''')
  421. cursor.execute('''
  422. CREATE TABLE IF NOT EXISTS keys(
  423. key STRING UNIQUE NOT NULL,
  424. used_by_user_id INTEGER,
  425. FOREIGN KEY (used_by_user_id) REFERENCES user(rowid)
  426. )
  427. ''')
  428. cursor.execute('''
  429. CREATE TABLE IF NOT EXISTS news(
  430. dt DATETIME NOT NULL DEFAULT CURRENT_TIMESTAMP,
  431. title VARCHAR(50) NOT NULL
  432. )
  433. ''')
  434. def _add_column_if_not_exists(cursor, query):
  435. if 'ALTER TABLE' not in query:
  436. raise ValueError('Only alter table queries allowed.')
  437. if 'ADD COLUMN' not in query:
  438. raise ValueError('Only add column queries allowed.')
  439. try:
  440. cursor.execute(query)
  441. except OperationalError as e: # if the column already exists this will happen
  442. if 'duplicate column name' not in e.args[0]:
  443. raise