model.py 30 KB

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