model.py 31 KB

12345678910111213141516171819202122232425262728293031323334353637383940414243444546474849505152535455565758596061626364656667686970717273747576777879808182838485868788899091929394959697989910010110210310410510610710810911011111211311411511611711811912012112212312412512612712812913013113213313413513613713813914014114214314414514614714814915015115215315415515615715815916016116216316416516616716816917017117217317417517617717817918018118218318418518618718818919019119219319419519619719819920020120220320420520620720820921021121221321421521621721821922022122222322422522622722822923023123223323423523623723823924024124224324424524624724824925025125225325425525625725825926026126226326426526626726826927027127227327427527627727827928028128228328428528628728828929029129229329429529629729829930030130230330430530630730830931031131231331431531631731831932032132232332432532632732832933033133233333433533633733833934034134234334434534634734834935035135235335435535635735835936036136236336436536636736836937037137237337437537637737837938038138238338438538638738838939039139239339439539639739839940040140240340440540640740840941041141241341441541641741841942042142242342442542642742842943043143243343443543643743843944044144244344444544644744844945045145245345445545645745845946046146246346446546646746846947047147247347447547647747847948048148248348448548648748848949049149249349449549649749849950050150250350450550650750850951051151251351451551651751851952052152252352452552652752852953053153253353453553653753853954054154254354454554654754854955055155255355455555655755855956056156256356456556656756856957057157257357457557657757857958058158258358458558658758858959059159259359459559659759859960060160260360460560660760860961061161261361461561661761861962062162262362462562662762862963063163263363463563663763863964064164264364464564664764864965065165265365465565665765865966066166266366466566666766866967067167267367467567667767867968068168268368468568668768868969069169269369469569669769869970070170270370470570670770870971071171271371471571671771871972072172272372472572672772872973073173273373473573673773873974074174274374474574674774874975075175275375475575675775875976076176276376476576676776876977077177277377477577677777877978078178278378478578678778878979079179279379479579679779879980080180280380480580680780880981081181281381481581681781881982082182282382482582682782882983083183283383483583683783883984084184284384484584684784884985085185285385485585685785885986086186286386486586686786886987087187287387487587687787887988088188288388488588688788888989089189289389489589689789889990090190290390490590690790890991091191291391491591691791891992092192292392492592692792892993093193293393493593693793893994094194294394494594694794894995095195295395495595695795895996096196296396496596696796896997097197297397497597697797897998098198298398498598698798898999099199299399499599699799899910001001100210031004100510061007100810091010101110121013101410151016101710181019102010211022102310241025102610271028102910301031103210331034103510361037103810391040104110421043104410451046104710481049105010511052105310541055105610571058105910601061106210631064106510661067106810691070107110721073107410751076107710781079108010811082108310841085108610871088108910901091109210931094109510961097109810991100110111021103110411051106110711081109111011111112
  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 get_user_id_by_session_id(session_id):
  176. connect()
  177. cursor.execute('''
  178. SELECT users.rowid
  179. FROM sessions, users
  180. WHERE sessions.session_id = ?
  181. AND users.rowid = sessions.user_id
  182. ''', (session_id,))
  183. ids = cursor.fetchone()
  184. if not ids:
  185. return False
  186. return ids[0]
  187. def get_user_id_by_name(username):
  188. connect()
  189. cursor.execute('''
  190. SELECT users.rowid
  191. FROM users
  192. WHERE username = ?
  193. ''', (username,))
  194. return cursor.fetchone()[0]
  195. def get_user_ownership(user_id):
  196. connect()
  197. cursor.execute('''
  198. SELECT
  199. ownables.name,
  200. ownership.amount,
  201. COALESCE (
  202. CASE -- sum score for each of the users ownables
  203. WHEN ownership.ownable_id = ? THEN 1
  204. ELSE (SELECT price
  205. FROM transactions
  206. WHERE ownable_id = ownership.ownable_id
  207. ORDER BY rowid DESC -- equivalent to ordering by dt
  208. LIMIT 1)
  209. END, 0) AS price,
  210. (SELECT MAX("limit")
  211. FROM orders, ownership o2
  212. WHERE o2.rowid = orders.ownership_id
  213. AND o2.ownable_id = ownership.ownable_id
  214. AND buy
  215. AND NOT stop_loss) AS bid,
  216. (SELECT MIN("limit")
  217. FROM orders, ownership o2
  218. WHERE o2.rowid = orders.ownership_id
  219. AND o2.ownable_id = ownership.ownable_id
  220. AND NOT buy
  221. AND NOT stop_loss) AS ask
  222. FROM ownership, ownables
  223. WHERE user_id = ?
  224. AND (ownership.amount > 0 OR ownership.ownable_id = ?)
  225. AND ownership.ownable_id = ownables.rowid
  226. ORDER BY ownables.rowid ASC
  227. ''', (currency_id(), user_id, currency_id(),))
  228. return cursor.fetchall()
  229. def activate_key(key, user_id):
  230. connect()
  231. cursor.execute('''
  232. UPDATE keys
  233. SET used_by_user_id = ?
  234. WHERE used_by_user_id IS NULL
  235. AND key = ?
  236. ''', (user_id, key,))
  237. send_ownable(bank_id(), user_id, CURRENCY_NAME, 1000)
  238. def bank_id():
  239. connect()
  240. cursor.execute('''
  241. SELECT users.rowid
  242. FROM users
  243. WHERE username = 'bank'
  244. ''')
  245. return cursor.fetchone()[0]
  246. def valid_session_id(session_id):
  247. connect()
  248. cursor.execute('''
  249. SELECT rowid
  250. FROM sessions
  251. WHERE session_id = ?
  252. ''', (session_id,))
  253. if cursor.fetchone():
  254. return True
  255. else:
  256. return False
  257. def get_user_orders(user_id):
  258. connect()
  259. cursor.execute('''
  260. SELECT
  261. CASE
  262. WHEN orders.buy THEN 'Buy'
  263. ELSE 'Sell'
  264. END,
  265. ownables.name,
  266. (orders.ordered_amount - orders.executed_amount) || '/' || orders.ordered_amount,
  267. orders."limit",
  268. CASE
  269. WHEN orders."limit" IS NULL THEN NULL
  270. WHEN orders.stop_loss THEN 'Yes'
  271. ELSE 'No'
  272. END,
  273. datetime(orders.expiry_dt, 'localtime'),
  274. orders.rowid
  275. FROM orders, ownables, ownership
  276. WHERE ownership.user_id = ?
  277. AND ownership.ownable_id = ownables.rowid
  278. AND orders.ownership_id = ownership.rowid
  279. ORDER BY ownables.name ASC, orders.stop_loss ASC, orders.buy DESC, orders."limit" ASC
  280. ''', (user_id,))
  281. return cursor.fetchall()
  282. def get_ownable_orders(user_id, ownable_id):
  283. connect()
  284. cursor.execute('''
  285. SELECT
  286. CASE
  287. WHEN ownership.user_id = ? THEN 'X'
  288. ELSE NULL
  289. END,
  290. CASE
  291. WHEN orders.buy THEN 'Buy'
  292. ELSE 'Sell'
  293. END,
  294. ownables.name,
  295. orders.ordered_amount - orders.executed_amount,
  296. orders."limit",
  297. datetime(orders.expiry_dt, 'localtime'),
  298. orders.rowid
  299. FROM orders, ownables, ownership
  300. WHERE ownership.ownable_id = ?
  301. AND ownership.ownable_id = ownables.rowid
  302. AND orders.ownership_id = ownership.rowid
  303. AND (orders.stop_loss IS NULL OR NOT orders.stop_loss)
  304. ORDER BY ownables.name ASC, orders.stop_loss ASC, orders.buy DESC, orders."limit" ASC
  305. ''', (user_id, ownable_id,))
  306. return cursor.fetchall()
  307. def sell_ordered_amount(user_id, ownable_id):
  308. connect()
  309. cursor.execute('''
  310. SELECT COALESCE(SUM(orders.ordered_amount - orders.executed_amount),0)
  311. FROM orders, ownership
  312. WHERE ownership.rowid = orders.ownership_id
  313. AND ownership.user_id = ?
  314. AND ownership.ownable_id = ?
  315. AND NOT orders.buy
  316. ''', (user_id, ownable_id))
  317. return cursor.fetchone()[0]
  318. def available_amount(user_id, ownable_id):
  319. connect()
  320. cursor.execute('''
  321. SELECT amount
  322. FROM ownership
  323. WHERE user_id = ?
  324. AND ownable_id = ?
  325. ''', (user_id, ownable_id))
  326. return cursor.fetchone()[0] - sell_ordered_amount(user_id, ownable_id)
  327. def user_owns_at_least(amount, user_id, ownable_id):
  328. connect()
  329. if not isinstance(amount, float) and not isinstance(amount, int):
  330. # comparison of float with strings does not work so well in sql
  331. raise AssertionError()
  332. cursor.execute('''
  333. SELECT rowid
  334. FROM ownership
  335. WHERE user_id = ?
  336. AND ownable_id = ?
  337. AND amount - ? >= ?
  338. ''', (user_id, ownable_id, sell_ordered_amount(user_id, ownable_id), amount))
  339. if cursor.fetchone():
  340. return True
  341. else:
  342. return False
  343. def news():
  344. connect()
  345. cursor.execute('''
  346. SELECT dt, title FROM
  347. (SELECT *, rowid
  348. FROM news
  349. ORDER BY rowid DESC -- equivalent to order by dt
  350. LIMIT 20) n
  351. ORDER BY rowid ASC -- equivalent to order by dt
  352. ''')
  353. return cursor.fetchall()
  354. def ownable_name_exists(name):
  355. connect()
  356. cursor.execute('''
  357. SELECT rowid
  358. FROM ownables
  359. WHERE name = ?
  360. ''', (name,))
  361. if cursor.fetchone():
  362. return True
  363. else:
  364. return False
  365. def new_stock(expiry, name=None):
  366. connect()
  367. while name is None:
  368. name = random_chars(6)
  369. if ownable_name_exists(name):
  370. name = None
  371. cursor.execute('''
  372. INSERT INTO ownables(name)
  373. VALUES (?)
  374. ''', (name,))
  375. new_news('A new stock can now be bought: ' + name)
  376. if random.getrandbits(1):
  377. new_news('Experts expect the price of ' + name + ' to fall')
  378. else:
  379. new_news('Experts expect the price of ' + name + ' to rise')
  380. amount = random.randrange(100, 10000)
  381. price = random.randrange(10000, 20000) / amount
  382. ownable_id = ownable_id_by_name(name)
  383. own(bank_id(), name, amount)
  384. bank_order(False,
  385. ownable_id,
  386. price,
  387. amount,
  388. expiry)
  389. return name
  390. def ownable_id_by_name(ownable_name):
  391. connect()
  392. cursor.execute('''
  393. SELECT rowid
  394. FROM ownables
  395. WHERE name = ?
  396. ''', (ownable_name,))
  397. return cursor.fetchone()[0]
  398. def get_ownership_id(ownable_id, user_id):
  399. connect()
  400. cursor.execute('''
  401. SELECT rowid
  402. FROM ownership
  403. WHERE ownable_id = ?
  404. AND user_id = ?
  405. ''', (ownable_id, user_id,))
  406. return cursor.fetchone()[0]
  407. def currency_id():
  408. connect()
  409. cursor.execute('''
  410. SELECT rowid
  411. FROM ownables
  412. WHERE name = ?
  413. ''', (CURRENCY_NAME,))
  414. return cursor.fetchone()[0]
  415. def user_money(user_id):
  416. connect()
  417. cursor.execute('''
  418. SELECT amount
  419. FROM ownership
  420. WHERE user_id = ?
  421. AND ownable_id = ?
  422. ''', (user_id, currency_id()))
  423. return cursor.fetchone()[0]
  424. def delete_order(order_id):
  425. connect()
  426. cursor.execute('''
  427. DELETE FROM orders
  428. WHERE rowid = ?
  429. ''', (order_id,))
  430. def current_value(ownable_id):
  431. connect()
  432. if ownable_id == currency_id():
  433. return 1
  434. cursor.execute('''SELECT price
  435. FROM transactions
  436. WHERE ownable_id = ?
  437. ORDER BY rowid DESC -- equivalent to order by dt
  438. LIMIT 1
  439. ''', (ownable_id,))
  440. return cursor.fetchone()[0]
  441. def execute_orders(ownable_id):
  442. connect()
  443. while True:
  444. # find order to execute
  445. cursor.execute('''
  446. -- two best orders
  447. SELECT * FROM (
  448. SELECT buy_order.*, sell_order.*, buyer.user_id, seller.user_id, buy_order.rowid, sell_order.rowid
  449. FROM orders buy_order, orders sell_order, ownership buyer, ownership seller
  450. WHERE buy_order.buy AND NOT sell_order.buy
  451. AND buyer.rowid = buy_order.ownership_id
  452. AND seller.rowid = sell_order.ownership_id
  453. AND buyer.ownable_id = ?
  454. AND seller.ownable_id = ?
  455. AND buy_order."limit" IS NULL
  456. AND sell_order."limit" IS NULL
  457. ORDER BY buy_order.rowid ASC,
  458. sell_order.rowid ASC
  459. LIMIT 1)
  460. UNION ALL -- best buy orders
  461. SELECT * FROM (
  462. SELECT buy_order.*, sell_order.*, buyer.user_id, seller.user_id, buy_order.rowid, sell_order.rowid
  463. FROM orders buy_order, orders sell_order, ownership buyer, ownership seller
  464. WHERE buy_order.buy AND NOT sell_order.buy
  465. AND buyer.rowid = buy_order.ownership_id
  466. AND seller.rowid = sell_order.ownership_id
  467. AND buyer.ownable_id = ?
  468. AND seller.ownable_id = ?
  469. AND buy_order."limit" IS NULL
  470. AND sell_order."limit" IS NOT NULL
  471. AND NOT sell_order.stop_loss
  472. ORDER BY sell_order."limit" ASC,
  473. buy_order.rowid ASC,
  474. sell_order.rowid ASC
  475. LIMIT 1)
  476. UNION ALL -- best sell orders
  477. SELECT * FROM (
  478. SELECT buy_order.*, sell_order.*, buyer.user_id, seller.user_id, buy_order.rowid, sell_order.rowid
  479. FROM orders buy_order, orders sell_order, ownership buyer, ownership seller
  480. WHERE buy_order.buy AND NOT sell_order.buy
  481. AND buyer.rowid = buy_order.ownership_id
  482. AND seller.rowid = sell_order.ownership_id
  483. AND buyer.ownable_id = ?
  484. AND seller.ownable_id = ?
  485. AND buy_order."limit" IS NOT NULL
  486. AND NOT buy_order.stop_loss
  487. AND sell_order."limit" IS NULL
  488. ORDER BY buy_order."limit" DESC,
  489. buy_order.rowid ASC,
  490. sell_order.rowid ASC
  491. LIMIT 1)
  492. UNION ALL -- both limit orders
  493. SELECT * FROM (
  494. SELECT buy_order.*, sell_order.*, buyer.user_id, seller.user_id, buy_order.rowid, sell_order.rowid
  495. FROM orders buy_order, orders sell_order, ownership buyer, ownership seller
  496. WHERE buy_order.buy AND NOT sell_order.buy
  497. AND buyer.rowid = buy_order.ownership_id
  498. AND seller.rowid = sell_order.ownership_id
  499. AND buyer.ownable_id = ?
  500. AND seller.ownable_id = ?
  501. AND buy_order."limit" IS NOT NULL
  502. AND sell_order."limit" IS NOT NULL
  503. AND sell_order."limit" <= buy_order."limit"
  504. AND NOT sell_order.stop_loss
  505. AND NOT buy_order.stop_loss
  506. ORDER BY buy_order."limit" DESC,
  507. sell_order."limit" ASC,
  508. buy_order.rowid ASC,
  509. sell_order.rowid ASC
  510. LIMIT 1)
  511. LIMIT 1
  512. ''', tuple(ownable_id for _ in range(8)))
  513. matching_orders = cursor.fetchone()
  514. # return type: (ownership_id,buy,limit,stop_loss,ordered_amount,executed_amount,expiry_dt,
  515. # ownership_id,buy,limit,stop_loss,ordered_amount,executed_amount,expiry_dt,
  516. # user_id,user_id,rowid,rowid)
  517. if not matching_orders:
  518. break
  519. buy_ownership_id, _, buy_limit, _, buy_order_amount, buy_executed_amount, buy_expiry_dt, \
  520. sell_ownership_id, _, sell_limit, _, sell_order_amount, sell_executed_amount, sell_expiry_dt, \
  521. buyer_id, seller_id, buy_order_id, sell_order_id \
  522. = matching_orders
  523. if buy_limit is None and sell_limit is None:
  524. price = current_value(ownable_id)
  525. elif buy_limit is None:
  526. price = sell_limit
  527. elif sell_limit is None:
  528. price = buy_limit
  529. else: # both not NULL
  530. # the price of the older order is used, just like in the real exchange
  531. if buy_order_id < sell_order_id:
  532. price = buy_limit
  533. else:
  534. price = sell_limit
  535. buyer_money = user_money(buyer_id)
  536. def _my_division(x, y):
  537. try:
  538. return floor(x / y)
  539. except ZeroDivisionError:
  540. return float('Inf')
  541. amount = min(buy_order_amount - buy_executed_amount,
  542. sell_order_amount - sell_executed_amount,
  543. _my_division(buyer_money, price))
  544. if amount == 0: # probable because buyer has not enough money
  545. delete_order(buy_order_id)
  546. continue
  547. buy_order_finished = (buy_order_amount - buy_executed_amount - amount <= 0) or (
  548. buyer_money - amount * price < price)
  549. sell_order_finished = (sell_order_amount - sell_executed_amount - amount <= 0)
  550. if price < 0 or amount <= 0: # price of 0 is possible though unlikely
  551. return AssertionError()
  552. # actually execute the order, but the bank does not send or receive anything
  553. if buyer_id != bank_id(): # buyer pays
  554. cursor.execute('''
  555. UPDATE ownership
  556. SET amount = amount - ?
  557. WHERE user_id = ?
  558. AND ownable_id = ?
  559. ''', (price * amount, buyer_id, currency_id()))
  560. if seller_id != bank_id(): # seller pays
  561. cursor.execute('''
  562. UPDATE ownership
  563. SET amount = amount - ?
  564. WHERE rowid = ?
  565. ''', (amount, sell_ownership_id))
  566. if buyer_id != bank_id(): # buyer receives
  567. cursor.execute('''
  568. UPDATE ownership
  569. SET amount = amount + ?
  570. WHERE rowid = ?
  571. ''', (amount, buy_ownership_id))
  572. if seller_id != bank_id(): # seller receives
  573. cursor.execute('''
  574. UPDATE ownership
  575. SET amount = amount + ?
  576. WHERE user_id = ?
  577. AND ownable_id = ?
  578. ''', (price * amount, seller_id, currency_id()))
  579. # update order execution state
  580. cursor.execute('''
  581. UPDATE orders
  582. SET executed_amount = executed_amount + ?
  583. WHERE rowid = ?
  584. OR rowid = ?
  585. ''', (amount, buy_order_id, sell_order_id))
  586. if buy_order_finished:
  587. delete_order(buy_order_id)
  588. if sell_order_finished:
  589. delete_order(sell_order_id)
  590. if seller_id != buyer_id: # prevent showing self-transactions
  591. cursor.execute('''
  592. INSERT INTO transactions
  593. (price, ownable_id, amount)
  594. VALUES(?, ?, ?)
  595. ''', (price, ownable_id, amount,))
  596. # trigger stop-loss orders
  597. if buyer_id != seller_id:
  598. cursor.execute('''
  599. UPDATE orders
  600. SET stop_loss = NULL,
  601. "limit" = NULL
  602. WHERE stop_loss IS NOT NULL
  603. AND stop_loss
  604. AND ? IN (SELECT ownable_id FROM ownership WHERE rowid = ownership_id)
  605. AND ((buy AND "limit" < ?) OR (NOT buy AND "limit" > ?))
  606. ''', (ownable_id, price, price,))
  607. def ownable_id_by_ownership_id(ownership_id):
  608. connect()
  609. cursor.execute('''
  610. SELECT ownable_id
  611. FROM ownership
  612. WHERE rowid = ?
  613. ''', (ownership_id,))
  614. return cursor.fetchone()[0]
  615. def ownable_name_by_id(ownable_id):
  616. connect()
  617. cursor.execute('''
  618. SELECT name
  619. FROM ownables
  620. WHERE rowid = ?
  621. ''', (ownable_id,))
  622. return cursor.fetchone()[0]
  623. def bank_order(buy, ownable_id, limit, amount, expiry):
  624. if not limit:
  625. raise AssertionError('The bank does not give away anything.')
  626. place_order(buy,
  627. get_ownership_id(ownable_id, bank_id()),
  628. limit,
  629. False,
  630. amount,
  631. expiry)
  632. ownable_name = ownable_name_by_id(ownable_id)
  633. new_news('External investors are selling ' + ownable_name + ' atm')
  634. def current_db_time(): # might differ from datetime.datetime.now() for time zone reasons
  635. connect()
  636. cursor.execute('''
  637. SELECT datetime('now')
  638. ''')
  639. return cursor.fetchone()[0]
  640. def place_order(buy, ownership_id, limit, stop_loss, amount, expiry):
  641. connect()
  642. cursor.execute('''
  643. INSERT INTO orders
  644. (buy, ownership_id, "limit", stop_loss, ordered_amount, expiry_dt)
  645. VALUES (?, ?, ?, ?, ?, ?)
  646. ''', (buy, ownership_id, limit, stop_loss, amount, expiry))
  647. execute_orders(ownable_id_by_ownership_id(ownership_id))
  648. return True
  649. def transactions(ownable_id, limit):
  650. connect()
  651. cursor.execute('''
  652. SELECT datetime(dt,'localtime'), amount, price
  653. FROM transactions
  654. WHERE ownable_id = ?
  655. ORDER BY rowid DESC -- equivalent to order by dt
  656. LIMIT ?
  657. ''', (ownable_id, limit,))
  658. return cursor.fetchall()
  659. def drop_expired_orders():
  660. connect()
  661. cursor.execute('''
  662. DELETE FROM orders
  663. WHERE expiry_dt < DATETIME('now')
  664. ''')
  665. return cursor.fetchall()
  666. def generate_keys(count=1):
  667. # source https://stackoverflow.com/questions/17049308/python-3-3-serial-key-generator-list-problems
  668. for i in range(count):
  669. key = '-'.join(random_chars(5) for _ in range(5))
  670. save_key(key)
  671. print(key)
  672. def user_has_order_with_id(session_id, order_id):
  673. connect()
  674. cursor.execute('''
  675. SELECT orders.rowid
  676. FROM orders, ownership, sessions
  677. WHERE orders.rowid = ?
  678. AND sessions.session_id = ?
  679. AND sessions.user_id = ownership.user_id
  680. AND ownership.rowid = orders.ownership_id
  681. ''', (order_id, session_id,))
  682. if cursor.fetchone():
  683. return True
  684. else:
  685. return False
  686. def leaderboard():
  687. connect()
  688. cursor.execute('''
  689. SELECT *
  690. FROM ( -- one score for each user
  691. SELECT
  692. username,
  693. SUM(CASE -- sum score for each of the users ownables
  694. WHEN ownership.ownable_id = ? THEN ownership.amount
  695. ELSE ownership.amount * (SELECT price
  696. FROM transactions
  697. WHERE ownable_id = ownership.ownable_id
  698. ORDER BY rowid DESC -- equivalent to ordering by dt
  699. LIMIT 1)
  700. END
  701. ) score
  702. FROM users, ownership
  703. WHERE ownership.user_id = users.rowid
  704. AND users.username != 'bank'
  705. GROUP BY users.rowid
  706. ) AS scores
  707. ORDER BY score DESC
  708. LIMIT 50
  709. ''', (currency_id(),))
  710. return cursor.fetchall()
  711. def user_wealth(user_id):
  712. connect()
  713. cursor.execute('''
  714. SELECT SUM(
  715. CASE -- sum score for each of the users ownables
  716. WHEN ownership.ownable_id = ? THEN ownership.amount
  717. ELSE ownership.amount * (SELECT price
  718. FROM transactions
  719. WHERE ownable_id = ownership.ownable_id
  720. ORDER BY rowid DESC -- equivalent to ordering by dt
  721. LIMIT 1)
  722. END
  723. ) score
  724. FROM ownership
  725. WHERE ownership.user_id = ?
  726. ''', (currency_id(), user_id,))
  727. return cursor.fetchone()[0]
  728. def change_password(session_id, password):
  729. connect()
  730. cursor.execute('''
  731. UPDATE users
  732. SET password = ?
  733. WHERE rowid = (SELECT user_id FROM sessions WHERE sessions.session_id = ?)
  734. ''', (password, session_id,))
  735. def sign_out_user(session_id):
  736. connect()
  737. cursor.execute('''
  738. DELETE FROM sessions
  739. WHERE user_id = (SELECT user_id FROM sessions s2 WHERE s2.session_id = ?)
  740. ''', (session_id,))
  741. def delete_user(user_id):
  742. connect()
  743. cursor.execute('''
  744. DELETE FROM sessions
  745. WHERE user_id = ?
  746. ''', (user_id,))
  747. cursor.execute('''
  748. DELETE FROM orders
  749. WHERE ownership_id IN (
  750. SELECT rowid FROM ownership WHERE user_id = ?)
  751. ''', (user_id,))
  752. cursor.execute('''
  753. DELETE FROM ownership
  754. WHERE user_id = ?
  755. ''', (user_id,))
  756. cursor.execute('''
  757. DELETE FROM keys
  758. WHERE used_by_user_id = ?
  759. ''', (user_id,))
  760. cursor.execute('''
  761. INSERT INTO news(title)
  762. VALUES ((SELECT username FROM users WHERE rowid = ?) || ' retired.')
  763. ''', (user_id,))
  764. cursor.execute('''
  765. DELETE FROM users
  766. WHERE rowid = ?
  767. ''', (user_id,))
  768. def delete_ownable(ownable_id):
  769. connect()
  770. cursor.execute('''
  771. DELETE FROM transactions
  772. WHERE ownable_id = ?
  773. ''', (ownable_id,))
  774. cursor.execute('''
  775. DELETE FROM orders
  776. WHERE ownership_id IN (
  777. SELECT rowid FROM ownership WHERE ownable_id = ?)
  778. ''', (ownable_id,))
  779. # only delete empty ownerships
  780. cursor.execute('''
  781. DELETE FROM ownership
  782. WHERE ownable_id = ?
  783. AND amount = 0
  784. ''', (ownable_id,))
  785. cursor.execute('''
  786. INSERT INTO news(title)
  787. VALUES ((SELECT name FROM ownables WHERE rowid = ?) || ' can not be traded any more.')
  788. ''', (ownable_id,))
  789. cursor.execute('''
  790. DELETE FROM ownables
  791. WHERE rowid = ?
  792. ''', (ownable_id,))
  793. def hash_all_users_passwords():
  794. connect()
  795. cursor.execute('''
  796. SELECT rowid, password
  797. FROM users
  798. ''')
  799. users = cursor.fetchall()
  800. for user in users:
  801. user_id = user[0]
  802. pw = user[1]
  803. valid_hash = True
  804. try:
  805. sha256_crypt.verify('password' + salt, pw)
  806. except ValueError:
  807. valid_hash = False
  808. if valid_hash:
  809. raise AssertionError('There is already a hashed password in the database! Be careful what you are doing!')
  810. pw = sha256_crypt.encrypt(pw + salt)
  811. cursor.execute('''
  812. UPDATE users
  813. SET password = ?
  814. WHERE rowid = ?
  815. ''', (pw, user_id,))
  816. def new_news(message):
  817. connect()
  818. cursor.execute('''
  819. INSERT INTO news(title)
  820. VALUES (?)
  821. ''', (message,))
  822. def abs_spread(ownable_id):
  823. connect()
  824. cursor.execute('''
  825. SELECT
  826. (SELECT MAX("limit")
  827. FROM orders, ownership
  828. WHERE ownership.rowid = orders.ownership_id
  829. AND ownership.ownable_id = ?
  830. AND buy
  831. AND NOT stop_loss) AS bid,
  832. (SELECT MIN("limit")
  833. FROM orders, ownership
  834. WHERE ownership.rowid = orders.ownership_id
  835. AND ownership.ownable_id = ?
  836. AND NOT buy
  837. AND NOT stop_loss) AS ask
  838. ''', (ownable_id, ownable_id,))
  839. return cursor.fetchone()
  840. def ownables():
  841. connect()
  842. cursor.execute('''
  843. SELECT name, course,
  844. (SELECT SUM(amount)
  845. FROM ownership
  846. WHERE ownership.ownable_id = ownables_with_course.rowid) market_size
  847. FROM (SELECT
  848. name, ownables.rowid,
  849. CASE WHEN ownables.rowid = ?
  850. THEN 1
  851. ELSE (SELECT price
  852. FROM transactions
  853. WHERE ownable_id = ownables.rowid
  854. ORDER BY rowid DESC -- equivalent to ordering by dt
  855. LIMIT 1) END course
  856. FROM ownables) ownables_with_course
  857. ''', (currency_id(),))
  858. data = cursor.fetchall()
  859. for idx in range(len(data)):
  860. # compute market cap
  861. row = data[idx]
  862. if row[1] is None:
  863. market_cap = None
  864. elif row[2] is None:
  865. market_cap = None
  866. else:
  867. market_cap = row[1] * row[2]
  868. data[idx] = (row[0], row[1], market_cap)
  869. return data
  870. def reset_bank():
  871. connect()
  872. cursor.execute('''
  873. DELETE FROM ownership
  874. WHERE user_id = ?
  875. ''', (bank_id(),))
  876. def cleanup():
  877. if connection is not None:
  878. connection.commit()
  879. connection.close()