model.py 30 KB

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