model.py 30 KB

1234567891011121314151617181920212223242526272829303132333435363738394041424344454647484950515253545556575859606162636465666768697071727374757677787980818283848586878889909192939495969798991001011021031041051061071081091101111121131141151161171181191201211221231241251261271281291301311321331341351361371381391401411421431441451461471481491501511521531541551561571581591601611621631641651661671681691701711721731741751761771781791801811821831841851861871881891901911921931941951961971981992002012022032042052062072082092102112122132142152162172182192202212222232242252262272282292302312322332342352362372382392402412422432442452462472482492502512522532542552562572582592602612622632642652662672682692702712722732742752762772782792802812822832842852862872882892902912922932942952962972982993003013023033043053063073083093103113123133143153163173183193203213223233243253263273283293303313323333343353363373383393403413423433443453463473483493503513523533543553563573583593603613623633643653663673683693703713723733743753763773783793803813823833843853863873883893903913923933943953963973983994004014024034044054064074084094104114124134144154164174184194204214224234244254264274284294304314324334344354364374384394404414424434444454464474484494504514524534544554564574584594604614624634644654664674684694704714724734744754764774784794804814824834844854864874884894904914924934944954964974984995005015025035045055065075085095105115125135145155165175185195205215225235245255265275285295305315325335345355365375385395405415425435445455465475485495505515525535545555565575585595605615625635645655665675685695705715725735745755765775785795805815825835845855865875885895905915925935945955965975985996006016026036046056066076086096106116126136146156166176186196206216226236246256266276286296306316326336346356366376386396406416426436446456466476486496506516526536546556566576586596606616626636646656666676686696706716726736746756766776786796806816826836846856866876886896906916926936946956966976986997007017027037047057067077087097107117127137147157167177187197207217227237247257267277287297307317327337347357367377387397407417427437447457467477487497507517527537547557567577587597607617627637647657667677687697707717727737747757767777787797807817827837847857867877887897907917927937947957967977987998008018028038048058068078088098108118128138148158168178188198208218228238248258268278288298308318328338348358368378388398408418428438448458468478488498508518528538548558568578588598608618628638648658668678688698708718728738748758768778788798808818828838848858868878888898908918928938948958968978988999009019029039049059069079089099109119129139149159169179189199209219229239249259269279289299309319329339349359369379389399409419429439449459469479489499509519529539549559569579589599609619629639649659669679689699709719729739749759769779789799809819829839849859869879889899909919929939949959969979989991000100110021003100410051006100710081009101010111012101310141015101610171018101910201021102210231024102510261027102810291030103110321033103410351036103710381039104010411042104310441045104610471048104910501051105210531054105510561057105810591060106110621063106410651066106710681069107010711072107310741075107610771078107910801081108210831084108510861087108810891090109110921093109410951096109710981099110011011102
  1. import random
  2. import re
  3. import sqlite3 as db
  4. import sys
  5. import uuid
  6. from math import floor
  7. from passlib.handlers.sha2_crypt import sha256_crypt
  8. import db_setup
  9. from game import CURRENCY_NAME
  10. from util import random_chars, salt
  11. from debug import debug
  12. # connection: db.Connection = None
  13. # cursor: db.Cursor = None
  14. connection = None # no type annotations in python 3.5
  15. cursor = None # no type annotations in python 3.5
  16. db_name = None
  17. def query_save_name():
  18. global db_name
  19. if debug:
  20. db_name = 'test.db'
  21. return
  22. while True:
  23. save_name = input('Name of the savegame: ')
  24. if re.match(r"[A-Za-z0-9.-]{0,50}", save_name):
  25. db_name = save_name + '.db'
  26. return
  27. else:
  28. print('Must match "[A-Za-z0-9.-]{0,50}"')
  29. def connect(reconnect=False):
  30. global connection
  31. global cursor
  32. global db_name
  33. if reconnect:
  34. connection.commit()
  35. connection.close()
  36. cursor = None
  37. connection = None
  38. db_name = None
  39. if connection is None or cursor is None:
  40. query_save_name()
  41. try:
  42. connection = db.connect(db_name)
  43. # connection.text_factory = lambda x: unicode(x, 'utf-8', 'ignore')
  44. cursor = connection.cursor()
  45. except db.Error as e:
  46. print("Database error %s:" % e.args[0])
  47. sys.exit(1)
  48. # finally:
  49. # if con is not None:
  50. # con.close()
  51. def setup():
  52. connect()
  53. db_setup.setup(cursor)
  54. connection.commit()
  55. def used_key_count():
  56. connect()
  57. cursor.execute('''
  58. SELECT COUNT(*) -- rarely executed, no index needed, O(n) query
  59. FROM keys
  60. WHERE used_by_user_id IS NOT NULL
  61. ''')
  62. return cursor.fetchone()[0]
  63. def login(username, password):
  64. connect()
  65. # do not allow login as bank or with empty password
  66. if username == 'bank' and not debug:
  67. return None
  68. if password == '' and not debug:
  69. return None
  70. cursor.execute('''
  71. SELECT rowid, password
  72. FROM users
  73. WHERE username = ?
  74. ''', (username,))
  75. data = cursor.fetchone()
  76. if not data:
  77. return None
  78. hashed_password = data[1]
  79. user_id = data[0]
  80. # if a ValueError occurs here, then most likely a password that was stored as plain text
  81. if sha256_crypt.verify(password + salt, hashed_password):
  82. return new_session(user_id)
  83. else:
  84. return None
  85. def register(username, password, game_key):
  86. connect()
  87. if username == '':
  88. return False
  89. if password == '':
  90. return False
  91. cursor.execute('''
  92. INSERT INTO users
  93. (username, password)
  94. VALUES (? , ?)
  95. ''', (username, password))
  96. own(get_user_id_by_name(username), CURRENCY_NAME)
  97. if game_key != '':
  98. if valid_key(game_key):
  99. activate_key(game_key, get_user_id_by_name(username))
  100. return True
  101. def own(user_id, ownable_name, amount=0):
  102. if not isinstance(ownable_name, str):
  103. return AssertionError('A name must be a string.')
  104. cursor.execute('''
  105. INSERT OR IGNORE INTO ownership (user_id, ownable_id, amount)
  106. SELECT ?, (SELECT rowid FROM ownables WHERE name = ?), ?
  107. ''', (user_id, ownable_name, amount))
  108. def send_ownable(from_user_id, to_user_id, ownable_name, amount):
  109. connect()
  110. if amount < 0:
  111. return False
  112. if from_user_id != bank_id():
  113. cursor.execute('''
  114. UPDATE ownership
  115. SET amount = amount - ?
  116. WHERE user_id = ?
  117. AND ownable_id = (SELECT rowid FROM ownables WHERE name = ?)
  118. ''', (amount, from_user_id, ownable_name,))
  119. cursor.execute('''
  120. UPDATE ownership
  121. SET amount = amount + ?
  122. WHERE user_id = ?
  123. AND ownable_id = (SELECT rowid FROM ownables WHERE name = ?)
  124. ''', (amount, to_user_id, ownable_name))
  125. return True
  126. def valid_key(key):
  127. connect()
  128. cursor.execute('''
  129. SELECT key
  130. FROM keys
  131. WHERE used_by_user_id IS NULL
  132. AND key = ?
  133. ''', (key,))
  134. if cursor.fetchone():
  135. return True
  136. else:
  137. return False
  138. def new_session(user_id):
  139. connect()
  140. session_id = str(uuid.uuid4())
  141. cursor.execute('''
  142. INSERT INTO SESSIONS
  143. (user_id, session_id)
  144. VALUES (? , ?)
  145. ''', (user_id, session_id))
  146. return session_id
  147. def save_key(key):
  148. connect()
  149. cursor.execute('''
  150. INSERT INTO keys
  151. (key)
  152. VALUES (?)
  153. ''', (key,))
  154. def drop_old_sessions():
  155. connect()
  156. cursor.execute(''' -- no need to optimize this very well
  157. DELETE FROM sessions
  158. WHERE
  159. (SELECT COUNT(*) as newer
  160. FROM sessions s2
  161. WHERE user_id = s2.user_id
  162. AND rowid < s2.rowid) >= 10
  163. ''')
  164. def user_exists(username):
  165. connect()
  166. cursor.execute('''
  167. SELECT rowid
  168. FROM users
  169. WHERE username = ?
  170. ''', (username,))
  171. if cursor.fetchone():
  172. return True
  173. else:
  174. return False
  175. def unused_keys():
  176. connect()
  177. cursor.execute('''
  178. SELECT key
  179. FROM keys
  180. WHERE used_by_user_id IS NULL
  181. ''')
  182. return [str(key[0]).strip().upper() for key in cursor.fetchall()]
  183. def get_user_id_by_session_id(session_id):
  184. connect()
  185. cursor.execute('''
  186. SELECT users.rowid
  187. FROM sessions, users
  188. WHERE sessions.session_id = ?
  189. AND users.rowid = sessions.user_id
  190. ''', (session_id,))
  191. ids = cursor.fetchone()
  192. if not ids:
  193. return False
  194. return ids[0]
  195. def get_user_id_by_name(username):
  196. connect()
  197. cursor.execute('''
  198. SELECT users.rowid
  199. FROM users
  200. WHERE username = ?
  201. ''', (username,))
  202. return cursor.fetchone()[0]
  203. def get_user_ownership(user_id):
  204. connect()
  205. cursor.execute('''
  206. SELECT
  207. ownables.name,
  208. ownership.amount,
  209. COALESCE (
  210. CASE -- sum score for each of the users ownables
  211. WHEN ownership.ownable_id = ? THEN 1
  212. ELSE (SELECT price
  213. FROM transactions
  214. WHERE ownable_id = ownership.ownable_id
  215. ORDER BY rowid DESC -- equivalent to ordering by dt
  216. LIMIT 1)
  217. END, 0) AS price,
  218. (SELECT MAX("limit")
  219. FROM orders, ownership o2
  220. WHERE o2.rowid = orders.ownership_id
  221. AND o2.ownable_id = ownership.ownable_id
  222. AND buy
  223. AND NOT stop_loss) AS bid,
  224. (SELECT MIN("limit")
  225. FROM orders, ownership o2
  226. WHERE o2.rowid = orders.ownership_id
  227. AND o2.ownable_id = ownership.ownable_id
  228. AND NOT buy
  229. AND NOT stop_loss) AS ask
  230. FROM ownership, ownables
  231. WHERE user_id = ?
  232. AND (ownership.amount > 0 OR ownership.ownable_id = ?)
  233. AND ownership.ownable_id = ownables.rowid
  234. ORDER BY ownables.rowid ASC
  235. ''', (currency_id(), user_id, currency_id(),))
  236. return cursor.fetchall()
  237. def activate_key(key, user_id):
  238. connect()
  239. cursor.execute('''
  240. UPDATE keys
  241. SET used_by_user_id = ?
  242. WHERE used_by_user_id IS NULL
  243. AND key = ?
  244. ''', (user_id, key,))
  245. send_ownable(bank_id(), user_id, CURRENCY_NAME, 1000)
  246. def bank_id():
  247. connect()
  248. cursor.execute('''
  249. SELECT users.rowid
  250. FROM users
  251. WHERE username = 'bank'
  252. ''')
  253. return cursor.fetchone()[0]
  254. def valid_session_id(session_id):
  255. connect()
  256. cursor.execute('''
  257. SELECT rowid
  258. FROM sessions
  259. WHERE session_id = ?
  260. ''', (session_id,))
  261. if cursor.fetchone():
  262. return True
  263. else:
  264. return False
  265. def get_user_orders(user_id):
  266. connect()
  267. cursor.execute('''
  268. SELECT
  269. CASE
  270. WHEN orders.buy THEN 'Buy'
  271. ELSE 'Sell'
  272. END,
  273. ownables.name,
  274. (orders.ordered_amount - orders.executed_amount) || '/' || orders.ordered_amount,
  275. orders."limit",
  276. CASE
  277. WHEN orders."limit" IS NULL THEN NULL
  278. WHEN orders.stop_loss THEN 'Yes'
  279. ELSE 'No'
  280. END,
  281. datetime(orders.expiry_dt, 'localtime'),
  282. orders.rowid
  283. FROM orders, ownables, ownership
  284. WHERE ownership.user_id = ?
  285. AND ownership.ownable_id = ownables.rowid
  286. AND orders.ownership_id = ownership.rowid
  287. ORDER BY ownables.name ASC, orders.stop_loss ASC, orders.buy DESC, orders."limit" ASC
  288. ''', (user_id,))
  289. return cursor.fetchall()
  290. def get_ownable_orders(user_id, ownable_id):
  291. connect()
  292. cursor.execute('''
  293. SELECT
  294. CASE
  295. WHEN ownership.user_id = ? THEN 'X'
  296. ELSE NULL
  297. END,
  298. CASE
  299. WHEN orders.buy THEN 'Buy'
  300. ELSE 'Sell'
  301. END,
  302. ownables.name,
  303. orders.ordered_amount - orders.executed_amount,
  304. orders."limit",
  305. datetime(orders.expiry_dt, 'localtime'),
  306. orders.rowid
  307. FROM orders, ownables, ownership
  308. WHERE ownership.ownable_id = ?
  309. AND ownership.ownable_id = ownables.rowid
  310. AND orders.ownership_id = ownership.rowid
  311. AND (orders.stop_loss IS NULL OR NOT orders.stop_loss)
  312. ORDER BY ownables.name ASC, orders.stop_loss ASC, orders.buy DESC, orders."limit" ASC
  313. ''', (user_id, ownable_id,))
  314. return cursor.fetchall()
  315. def sell_ordered_amount(user_id, ownable_id):
  316. connect()
  317. cursor.execute('''
  318. SELECT COALESCE(SUM(orders.ordered_amount - orders.executed_amount),0)
  319. FROM orders, ownership
  320. WHERE ownership.rowid = orders.ownership_id
  321. AND ownership.user_id = ?
  322. AND ownership.ownable_id = ?
  323. AND NOT orders.buy
  324. ''', (user_id, ownable_id))
  325. return cursor.fetchone()[0]
  326. def available_amount(user_id, ownable_id):
  327. connect()
  328. cursor.execute('''
  329. SELECT amount
  330. FROM ownership
  331. WHERE user_id = ?
  332. AND ownable_id = ?
  333. ''', (user_id, ownable_id))
  334. return cursor.fetchone()[0] - sell_ordered_amount(user_id, ownable_id)
  335. def user_owns_at_least(amount, user_id, ownable_id):
  336. connect()
  337. if not isinstance(amount, float) and not isinstance(amount, int):
  338. # comparison of float with strings does not work so well in sql
  339. raise AssertionError()
  340. cursor.execute('''
  341. SELECT rowid
  342. FROM ownership
  343. WHERE user_id = ?
  344. AND ownable_id = ?
  345. AND amount - ? >= ?
  346. ''', (user_id, ownable_id, sell_ordered_amount(user_id, ownable_id), amount))
  347. if cursor.fetchone():
  348. return True
  349. else:
  350. return False
  351. def news():
  352. connect()
  353. cursor.execute('''
  354. SELECT dt, title FROM
  355. (SELECT *, rowid
  356. FROM news
  357. ORDER BY rowid DESC -- equivalent to order by dt
  358. LIMIT 20) n
  359. ORDER BY rowid ASC -- equivalent to order by dt
  360. ''')
  361. return cursor.fetchall()
  362. def ownable_name_exists(name):
  363. connect()
  364. cursor.execute('''
  365. SELECT rowid
  366. FROM ownables
  367. WHERE name = ?
  368. ''', (name,))
  369. if cursor.fetchone():
  370. return True
  371. else:
  372. return False
  373. def new_stock(expiry, name=None):
  374. connect()
  375. while name is None:
  376. name = random_chars(6)
  377. if ownable_name_exists(name):
  378. name = None
  379. cursor.execute('''
  380. INSERT INTO ownables(name)
  381. VALUES (?)
  382. ''', (name,))
  383. new_news('A new stock can now be bought: ' + name)
  384. if random.getrandbits(1):
  385. new_news('Experts expect the price of ' + name + ' to fall')
  386. else:
  387. new_news('Experts expect the price of ' + name + ' to rise')
  388. amount = random.randrange(100, 10000)
  389. price = random.randrange(10000, 20000) / amount
  390. ownable_id = ownable_id_by_name(name)
  391. own(bank_id(), name, amount)
  392. bank_order(False,
  393. ownable_id,
  394. price,
  395. amount,
  396. expiry)
  397. return name
  398. def ownable_id_by_name(ownable_name):
  399. connect()
  400. cursor.execute('''
  401. SELECT rowid
  402. FROM ownables
  403. WHERE name = ?
  404. ''', (ownable_name,))
  405. return cursor.fetchone()[0]
  406. def get_ownership_id(ownable_id, user_id):
  407. connect()
  408. cursor.execute('''
  409. SELECT rowid
  410. FROM ownership
  411. WHERE ownable_id = ?
  412. AND user_id = ?
  413. ''', (ownable_id, user_id,))
  414. return cursor.fetchone()[0]
  415. def currency_id():
  416. connect()
  417. cursor.execute('''
  418. SELECT rowid
  419. FROM ownables
  420. WHERE name = ?
  421. ''', (CURRENCY_NAME,))
  422. return cursor.fetchone()[0]
  423. def user_money(user_id):
  424. connect()
  425. cursor.execute('''
  426. SELECT amount
  427. FROM ownership
  428. WHERE user_id = ?
  429. AND ownable_id = ?
  430. ''', (user_id, currency_id()))
  431. return cursor.fetchone()[0]
  432. def delete_order(order_id):
  433. connect()
  434. cursor.execute('''
  435. DELETE FROM orders
  436. WHERE rowid = ?
  437. ''', (order_id,))
  438. def current_value(ownable_id):
  439. connect()
  440. if ownable_id == currency_id():
  441. return 1
  442. cursor.execute('''SELECT price
  443. FROM transactions
  444. WHERE ownable_id = ?
  445. ORDER BY rowid DESC -- equivalent to order by dt
  446. LIMIT 1
  447. ''', (ownable_id,))
  448. return cursor.fetchone()[0]
  449. def execute_orders(ownable_id):
  450. connect()
  451. while True:
  452. # find order to execute
  453. cursor.execute('''
  454. -- two best orders
  455. SELECT * FROM (
  456. SELECT buy_order.*, sell_order.*, buyer.user_id, seller.user_id, buy_order.rowid, sell_order.rowid
  457. FROM orders buy_order, orders sell_order, ownership buyer, ownership seller
  458. WHERE buy_order.buy AND NOT sell_order.buy
  459. AND buyer.rowid = buy_order.ownership_id
  460. AND seller.rowid = sell_order.ownership_id
  461. AND buyer.ownable_id = ?
  462. AND seller.ownable_id = ?
  463. AND buy_order."limit" IS NULL
  464. AND sell_order."limit" IS NULL
  465. ORDER BY buy_order.rowid ASC,
  466. sell_order.rowid ASC
  467. LIMIT 1)
  468. UNION ALL -- best buy orders
  469. SELECT * FROM (
  470. SELECT buy_order.*, sell_order.*, buyer.user_id, seller.user_id, buy_order.rowid, sell_order.rowid
  471. FROM orders buy_order, orders sell_order, ownership buyer, ownership seller
  472. WHERE buy_order.buy AND NOT sell_order.buy
  473. AND buyer.rowid = buy_order.ownership_id
  474. AND seller.rowid = sell_order.ownership_id
  475. AND buyer.ownable_id = ?
  476. AND seller.ownable_id = ?
  477. AND buy_order."limit" IS NULL
  478. AND sell_order."limit" IS NOT NULL
  479. AND NOT sell_order.stop_loss
  480. ORDER BY sell_order."limit" ASC,
  481. buy_order.rowid ASC,
  482. sell_order.rowid ASC
  483. LIMIT 1)
  484. UNION ALL -- best sell orders
  485. SELECT * FROM (
  486. SELECT buy_order.*, sell_order.*, buyer.user_id, seller.user_id, buy_order.rowid, sell_order.rowid
  487. FROM orders buy_order, orders sell_order, ownership buyer, ownership seller
  488. WHERE buy_order.buy AND NOT sell_order.buy
  489. AND buyer.rowid = buy_order.ownership_id
  490. AND seller.rowid = sell_order.ownership_id
  491. AND buyer.ownable_id = ?
  492. AND seller.ownable_id = ?
  493. AND buy_order."limit" IS NOT NULL
  494. AND NOT buy_order.stop_loss
  495. AND sell_order."limit" IS NULL
  496. ORDER BY buy_order."limit" DESC,
  497. buy_order.rowid ASC,
  498. sell_order.rowid ASC
  499. LIMIT 1)
  500. UNION ALL -- both limit orders
  501. SELECT * FROM (
  502. SELECT buy_order.*, sell_order.*, buyer.user_id, seller.user_id, buy_order.rowid, sell_order.rowid
  503. FROM orders buy_order, orders sell_order, ownership buyer, ownership seller
  504. WHERE buy_order.buy AND NOT sell_order.buy
  505. AND buyer.rowid = buy_order.ownership_id
  506. AND seller.rowid = sell_order.ownership_id
  507. AND buyer.ownable_id = ?
  508. AND seller.ownable_id = ?
  509. AND buy_order."limit" IS NOT NULL
  510. AND sell_order."limit" IS NOT NULL
  511. AND sell_order."limit" <= buy_order."limit"
  512. AND NOT sell_order.stop_loss
  513. AND NOT buy_order.stop_loss
  514. ORDER BY buy_order."limit" DESC,
  515. sell_order."limit" ASC,
  516. buy_order.rowid ASC,
  517. sell_order.rowid ASC
  518. LIMIT 1)
  519. LIMIT 1
  520. ''', tuple(ownable_id for _ in range(8)))
  521. matching_orders = cursor.fetchone()
  522. # return type: (ownership_id,buy,limit,stop_loss,ordered_amount,executed_amount,expiry_dt,
  523. # ownership_id,buy,limit,stop_loss,ordered_amount,executed_amount,expiry_dt,
  524. # user_id,user_id,rowid,rowid)
  525. if not matching_orders:
  526. break
  527. buy_ownership_id, _, buy_limit, _, buy_order_amount, buy_executed_amount, buy_expiry_dt, \
  528. sell_ownership_id, _, sell_limit, _, sell_order_amount, sell_executed_amount, sell_expiry_dt, \
  529. buyer_id, seller_id, buy_order_id, sell_order_id \
  530. = matching_orders
  531. if buy_limit is None and sell_limit is None:
  532. price = current_value(ownable_id)
  533. elif buy_limit is None:
  534. price = sell_limit
  535. elif sell_limit is None:
  536. price = buy_limit
  537. else: # both not NULL
  538. # the price of the older order is used, just like in the real exchange
  539. if buy_order_id < sell_order_id:
  540. price = buy_limit
  541. else:
  542. price = sell_limit
  543. buyer_money = user_money(buyer_id)
  544. def _my_division(x, y):
  545. try:
  546. return floor(x / y)
  547. except ZeroDivisionError:
  548. return float('Inf')
  549. amount = min(buy_order_amount - buy_executed_amount,
  550. sell_order_amount - sell_executed_amount,
  551. _my_division(buyer_money, price))
  552. if amount == 0: # probable because buyer has not enough money
  553. delete_order(buy_order_id)
  554. continue
  555. buy_order_finished = (buy_order_amount - buy_executed_amount - amount <= 0) or (
  556. buyer_money - amount * price < price)
  557. sell_order_finished = (sell_order_amount - sell_executed_amount - amount <= 0)
  558. if price < 0 or amount <= 0: # price of 0 is possible though unlikely
  559. return AssertionError()
  560. # actually execute the order, but the bank does not send or receive anything
  561. if buyer_id != bank_id(): # buyer pays
  562. cursor.execute('''
  563. UPDATE ownership
  564. SET amount = amount - ?
  565. WHERE user_id = ?
  566. AND ownable_id = ?
  567. ''', (price * amount, buyer_id, currency_id()))
  568. if seller_id != bank_id(): # seller pays
  569. cursor.execute('''
  570. UPDATE ownership
  571. SET amount = amount - ?
  572. WHERE rowid = ?
  573. ''', (amount, sell_ownership_id))
  574. if buyer_id != bank_id(): # buyer receives
  575. cursor.execute('''
  576. UPDATE ownership
  577. SET amount = amount + ?
  578. WHERE rowid = ?
  579. ''', (amount, buy_ownership_id))
  580. if seller_id != bank_id(): # seller receives
  581. cursor.execute('''
  582. UPDATE ownership
  583. SET amount = amount + ?
  584. WHERE user_id = ?
  585. AND ownable_id = ?
  586. ''', (price * amount, seller_id, currency_id()))
  587. # update order execution state
  588. cursor.execute('''
  589. UPDATE orders
  590. SET executed_amount = executed_amount + ?
  591. WHERE rowid = ?
  592. OR rowid = ?
  593. ''', (amount, buy_order_id, sell_order_id))
  594. if buy_order_finished:
  595. delete_order(buy_order_id)
  596. if sell_order_finished:
  597. delete_order(sell_order_id)
  598. if seller_id != buyer_id: # prevent showing self-transactions
  599. cursor.execute('''
  600. INSERT INTO transactions
  601. (price, ownable_id, amount)
  602. VALUES(?, ?, ?)
  603. ''', (price, ownable_id, amount,))
  604. # trigger stop-loss orders
  605. if buyer_id != seller_id:
  606. cursor.execute('''
  607. UPDATE orders
  608. SET stop_loss = NULL,
  609. "limit" = NULL
  610. WHERE stop_loss IS NOT NULL
  611. AND stop_loss
  612. AND ? IN (SELECT ownable_id FROM ownership WHERE rowid = ownership_id)
  613. AND ((buy AND "limit" < ?) OR (NOT buy AND "limit" > ?))
  614. ''', (ownable_id, price, price,))
  615. def ownable_id_by_ownership_id(ownership_id):
  616. connect()
  617. cursor.execute('''
  618. SELECT ownable_id
  619. FROM ownership
  620. WHERE rowid = ?
  621. ''', (ownership_id,))
  622. return cursor.fetchone()[0]
  623. def ownable_name_by_id(ownable_id):
  624. connect()
  625. cursor.execute('''
  626. SELECT name
  627. FROM ownables
  628. WHERE rowid = ?
  629. ''', (ownable_id,))
  630. return cursor.fetchone()[0]
  631. def bank_order(buy, ownable_id, limit, amount, expiry):
  632. if not limit:
  633. raise AssertionError('The bank does not give away anything.')
  634. place_order(buy,
  635. get_ownership_id(ownable_id, bank_id()),
  636. limit,
  637. False,
  638. amount,
  639. expiry)
  640. ownable_name = ownable_name_by_id(ownable_id)
  641. new_news('External investors are selling ' + ownable_name + ' atm')
  642. def current_db_time(): # might differ from datetime.datetime.now() for time zone reasons
  643. connect()
  644. cursor.execute('''
  645. SELECT datetime('now')
  646. ''')
  647. return cursor.fetchone()[0]
  648. def place_order(buy, ownership_id, limit, stop_loss, amount, expiry):
  649. connect()
  650. cursor.execute('''
  651. INSERT INTO orders
  652. (buy, ownership_id, "limit", stop_loss, ordered_amount, expiry_dt)
  653. VALUES (?, ?, ?, ?, ?, ?)
  654. ''', (buy, ownership_id, limit, stop_loss, amount, expiry))
  655. execute_orders(ownable_id_by_ownership_id(ownership_id))
  656. return True
  657. def transactions(ownable_id, limit):
  658. connect()
  659. cursor.execute('''
  660. SELECT datetime(dt,'localtime'), amount, price
  661. FROM transactions
  662. WHERE ownable_id = ?
  663. ORDER BY rowid DESC -- equivalent to order by dt
  664. LIMIT ?
  665. ''', (ownable_id, limit,))
  666. return cursor.fetchall()
  667. def drop_expired_orders():
  668. connect()
  669. cursor.execute('''
  670. DELETE FROM orders
  671. WHERE expiry_dt < DATETIME('now')
  672. ''')
  673. return cursor.fetchall()
  674. def generate_keys(count=1):
  675. # source https://stackoverflow.com/questions/17049308/python-3-3-serial-key-generator-list-problems
  676. for i in range(count):
  677. key = '-'.join(random_chars(5) for _ in range(5))
  678. save_key(key)
  679. print(key)
  680. def user_has_order_with_id(session_id, order_id):
  681. connect()
  682. cursor.execute('''
  683. SELECT orders.rowid
  684. FROM orders, ownership, sessions
  685. WHERE orders.rowid = ?
  686. AND sessions.session_id = ?
  687. AND sessions.user_id = ownership.user_id
  688. AND ownership.rowid = orders.ownership_id
  689. ''', (order_id, session_id,))
  690. if cursor.fetchone():
  691. return True
  692. else:
  693. return False
  694. def leaderboard():
  695. connect()
  696. cursor.execute('''
  697. SELECT *
  698. FROM ( -- one score for each user
  699. SELECT
  700. username,
  701. SUM(CASE -- sum score for each of the users ownables
  702. WHEN ownership.ownable_id = ? THEN ownership.amount
  703. ELSE ownership.amount * (SELECT price
  704. FROM transactions
  705. WHERE ownable_id = ownership.ownable_id
  706. ORDER BY rowid DESC -- equivalent to ordering by dt
  707. LIMIT 1)
  708. END
  709. ) score
  710. FROM users, ownership
  711. WHERE ownership.user_id = users.rowid
  712. AND users.username != 'bank'
  713. GROUP BY users.rowid
  714. ) AS scores
  715. ORDER BY score DESC
  716. LIMIT 50
  717. ''', (currency_id(),))
  718. return cursor.fetchall()
  719. def user_wealth(user_id):
  720. connect()
  721. cursor.execute('''
  722. SELECT SUM(
  723. CASE -- sum score for each of the users ownables
  724. WHEN ownership.ownable_id = ? THEN ownership.amount
  725. ELSE ownership.amount * (SELECT price
  726. FROM transactions
  727. WHERE ownable_id = ownership.ownable_id
  728. ORDER BY rowid DESC -- equivalent to ordering by dt
  729. LIMIT 1)
  730. END
  731. ) score
  732. FROM ownership
  733. WHERE ownership.user_id = ?
  734. ''', (currency_id(), user_id,))
  735. return cursor.fetchone()[0]
  736. def change_password(session_id, password):
  737. connect()
  738. cursor.execute('''
  739. UPDATE users
  740. SET password = ?
  741. WHERE rowid = (SELECT user_id FROM sessions WHERE sessions.session_id = ?)
  742. ''', (password, session_id,))
  743. def sign_out_user(session_id):
  744. connect()
  745. cursor.execute('''
  746. DELETE FROM sessions
  747. WHERE user_id = (SELECT user_id FROM sessions s2 WHERE s2.session_id = ?)
  748. ''', (session_id,))
  749. def delete_user(user_id):
  750. connect()
  751. cursor.execute('''
  752. DELETE FROM sessions
  753. WHERE user_id = ?
  754. ''', (user_id,))
  755. cursor.execute('''
  756. DELETE FROM orders
  757. WHERE ownership_id IN (
  758. SELECT rowid FROM ownership WHERE user_id = ?)
  759. ''', (user_id,))
  760. cursor.execute('''
  761. DELETE FROM ownership
  762. WHERE user_id = ?
  763. ''', (user_id,))
  764. cursor.execute('''
  765. DELETE FROM keys
  766. WHERE used_by_user_id = ?
  767. ''', (user_id,))
  768. cursor.execute('''
  769. INSERT INTO news(title)
  770. VALUES ((SELECT username FROM users WHERE rowid = ?) || ' retired.')
  771. ''', (user_id,))
  772. cursor.execute('''
  773. DELETE FROM users
  774. WHERE rowid = ?
  775. ''', (user_id,))
  776. def delete_ownable(ownable_id):
  777. connect()
  778. cursor.execute('''
  779. DELETE FROM transactions
  780. WHERE ownable_id = ?
  781. ''', (ownable_id,))
  782. cursor.execute('''
  783. DELETE FROM orders
  784. WHERE ownership_id IN (
  785. SELECT rowid FROM ownership WHERE ownable_id = ?)
  786. ''', (ownable_id,))
  787. # only delete empty ownerships
  788. cursor.execute('''
  789. DELETE FROM ownership
  790. WHERE ownable_id = ?
  791. AND amount = 0
  792. ''', (ownable_id,))
  793. cursor.execute('''
  794. INSERT INTO news(title)
  795. VALUES ((SELECT name FROM ownables WHERE rowid = ?) || ' can not be traded any more.')
  796. ''', (ownable_id,))
  797. cursor.execute('''
  798. DELETE FROM ownables
  799. WHERE rowid = ?
  800. ''', (ownable_id,))
  801. def hash_all_users_passwords():
  802. connect()
  803. cursor.execute('''
  804. SELECT rowid, password
  805. FROM users
  806. ''')
  807. users = cursor.fetchall()
  808. for user in users:
  809. user_id = user[0]
  810. pw = user[1]
  811. valid_hash = True
  812. try:
  813. sha256_crypt.verify('password' + salt, pw)
  814. except ValueError:
  815. valid_hash = False
  816. if valid_hash:
  817. raise AssertionError('There is already a hashed password in the database! Be careful what you are doing!')
  818. pw = sha256_crypt.encrypt(pw + salt)
  819. cursor.execute('''
  820. UPDATE users
  821. SET password = ?
  822. WHERE rowid = ?
  823. ''', (pw, user_id,))
  824. def new_news(message):
  825. connect()
  826. cursor.execute('''
  827. INSERT INTO news(title)
  828. VALUES (?)
  829. ''', (message,))
  830. def ownables():
  831. connect()
  832. cursor.execute('''
  833. SELECT name, course,
  834. (SELECT SUM(amount)
  835. FROM ownership
  836. WHERE ownership.ownable_id = ownables_with_course.rowid) market_size
  837. FROM (SELECT
  838. name, ownables.rowid,
  839. CASE WHEN ownables.rowid = ?
  840. THEN 1
  841. ELSE (SELECT price
  842. FROM transactions
  843. WHERE ownable_id = ownables.rowid
  844. ORDER BY rowid DESC -- equivalent to ordering by dt
  845. LIMIT 1) END course
  846. FROM ownables) ownables_with_course
  847. ''', (currency_id(),))
  848. data = cursor.fetchall()
  849. for idx in range(len(data)):
  850. # compute market cap
  851. row = data[idx]
  852. if row[1] is None:
  853. market_cap = None
  854. elif row[2] is None:
  855. market_cap = None
  856. else:
  857. market_cap = row[1] * row[2]
  858. data[idx] = (row[0], row[1], market_cap)
  859. return data
  860. def reset_bank():
  861. connect()
  862. cursor.execute('''
  863. DELETE FROM ownership
  864. WHERE user_id = ?
  865. ''', (bank_id(),))
  866. def cleanup():
  867. if connection is not None:
  868. connection.commit()
  869. connection.close()