1
1

model.py 29 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724725726727728729730731732733734735736737738739740741742743744745746747748749750751752753754755756757758759760761762763764765766767768769770771772773774775776777778779780781782783784785786787788789790791792793794795796797798799800801802803804805806807808809810811812813814815816817818819820821822823824825826827828829830831832833834835836837838839840841842843844845846847848849850851852853854855856857858859860861862863864865866867868869870871872873874875876877878879880881882883884885886887888889890891892893894895896897898899900901902903904905906907908909910911912913914915916917918919920921922923924925926927928929930931932933934935936937938939940941942943944945946947948949950951952953954955956957958959960961962963964965966967968969970971972973974975976977978979980981982983984985986987988989990991992993994995996997998999100010011002100310041005100610071008100910101011101210131014101510161017101810191020102110221023102410251026102710281029103010311032103310341035103610371038103910401041104210431044104510461047104810491050105110521053
  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(ownable_id):
  290. connect()
  291. cursor.execute('''
  292. SELECT
  293. CASE
  294. WHEN orders.buy THEN 'Buy'
  295. ELSE 'Sell'
  296. END,
  297. ownables.name,
  298. orders.ordered_amount - orders.executed_amount,
  299. orders."limit",
  300. CASE
  301. WHEN orders."limit" IS NULL THEN NULL
  302. WHEN orders.stop_loss THEN 'Yes'
  303. ELSE 'No'
  304. END,
  305. datetime(orders.expiry_dt, 'localtime'),
  306. orders.rowid
  307. FROM orders, ownables, ownership
  308. WHERE ownership.ownable_id = ?
  309. AND ownership.ownable_id = ownables.rowid
  310. AND orders.ownership_id = ownership.rowid
  311. ORDER BY ownables.name ASC, orders.stop_loss ASC, orders.buy DESC, orders."limit" ASC
  312. ''', (ownable_id,))
  313. return cursor.fetchall()
  314. def sell_ordered_amount(user_id, ownable_id):
  315. connect()
  316. cursor.execute('''
  317. SELECT COALESCE(SUM(orders.ordered_amount - orders.executed_amount),0)
  318. FROM orders, ownership
  319. WHERE ownership.rowid = orders.ownership_id
  320. AND ownership.user_id = ?
  321. AND ownership.ownable_id = ?
  322. AND NOT orders.buy
  323. ''', (user_id, ownable_id))
  324. return cursor.fetchone()[0]
  325. def available_amount(user_id, ownable_id):
  326. connect()
  327. cursor.execute('''
  328. SELECT amount
  329. FROM ownership
  330. WHERE user_id = ?
  331. AND ownable_id = ?
  332. ''', (user_id, ownable_id))
  333. return cursor.fetchone()[0] - sell_ordered_amount(user_id, ownable_id)
  334. def user_owns_at_least(amount, user_id, ownable_id):
  335. connect()
  336. if not isinstance(amount, float) and not isinstance(amount, int):
  337. # comparison of float with strings does not work so well in sql
  338. raise AssertionError()
  339. cursor.execute('''
  340. SELECT rowid
  341. FROM ownership
  342. WHERE user_id = ?
  343. AND ownable_id = ?
  344. AND amount - ? >= ?
  345. ''', (user_id, ownable_id, sell_ordered_amount(user_id, ownable_id), amount))
  346. if cursor.fetchone():
  347. return True
  348. else:
  349. return False
  350. def news():
  351. connect()
  352. cursor.execute('''
  353. SELECT * FROM
  354. (SELECT *
  355. FROM news
  356. ORDER BY rowid DESC -- equivalent to order by dt
  357. LIMIT 20) n
  358. ORDER BY rowid ASC -- equivalent to order by dt
  359. ''')
  360. return cursor.fetchall()
  361. def ownable_name_exists(name):
  362. connect()
  363. cursor.execute('''
  364. SELECT rowid
  365. FROM ownables
  366. WHERE name = ?
  367. ''', (name,))
  368. if cursor.fetchone():
  369. return True
  370. else:
  371. return False
  372. def new_stock(timeout=60, name=None):
  373. connect()
  374. while name is None:
  375. name = random_chars(6)
  376. if ownable_name_exists(name):
  377. name = None
  378. cursor.execute('''
  379. INSERT INTO ownables(name)
  380. VALUES (?)
  381. ''', (name,))
  382. new_news('A new stock can now be bought: ' + name)
  383. if random.getrandbits(1):
  384. new_news('Experts expect the price of ' + name + ' to fall')
  385. else:
  386. new_news('Experts expect the price of ' + name + ' to rise')
  387. amount = random.randrange(100, 10000)
  388. price = random.randrange(10000, 20000) / amount
  389. ownable_id = ownable_id_by_name(name)
  390. own(bank_id(), name)
  391. bank_order(False,
  392. ownable_id,
  393. price,
  394. amount,
  395. timeout)
  396. return name
  397. def new_stocks(timeout=60, count=1):
  398. return [new_stock(timeout=timeout) for _ in range(count)]
  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. cursor.execute('''SELECT price
  442. FROM transactions
  443. WHERE ownable_id = ?
  444. ORDER BY rowid DESC -- equivalent to order by dt
  445. LIMIT 1
  446. ''', (ownable_id,))
  447. return cursor.fetchone()[0]
  448. def execute_orders(ownable_id):
  449. connect()
  450. while True:
  451. # find order to execute
  452. cursor.execute('''
  453. -- two best orders
  454. SELECT * FROM (
  455. SELECT buy_order.*, sell_order.*, buyer.user_id, seller.user_id, buy_order.rowid, sell_order.rowid
  456. FROM orders buy_order, orders sell_order, ownership buyer, ownership seller
  457. WHERE buy_order.buy AND NOT sell_order.buy
  458. AND buyer.rowid = buy_order.ownership_id
  459. AND seller.rowid = sell_order.ownership_id
  460. AND buyer.ownable_id = ?
  461. AND seller.ownable_id = ?
  462. AND buy_order."limit" IS NULL
  463. AND sell_order."limit" IS NULL
  464. ORDER BY buy_order.rowid ASC,
  465. sell_order.rowid ASC
  466. LIMIT 1)
  467. UNION ALL -- best buy orders
  468. SELECT * FROM (
  469. SELECT buy_order.*, sell_order.*, buyer.user_id, seller.user_id, buy_order.rowid, sell_order.rowid
  470. FROM orders buy_order, orders sell_order, ownership buyer, ownership seller
  471. WHERE buy_order.buy AND NOT sell_order.buy
  472. AND buyer.rowid = buy_order.ownership_id
  473. AND seller.rowid = sell_order.ownership_id
  474. AND buyer.ownable_id = ?
  475. AND seller.ownable_id = ?
  476. AND buy_order."limit" IS NULL
  477. AND sell_order."limit" IS NOT NULL
  478. AND NOT sell_order.stop_loss
  479. ORDER BY sell_order."limit" ASC,
  480. buy_order.rowid ASC,
  481. sell_order.rowid ASC
  482. LIMIT 1)
  483. UNION ALL -- best sell orders
  484. SELECT * FROM (
  485. SELECT buy_order.*, sell_order.*, buyer.user_id, seller.user_id, buy_order.rowid, sell_order.rowid
  486. FROM orders buy_order, orders sell_order, ownership buyer, ownership seller
  487. WHERE buy_order.buy AND NOT sell_order.buy
  488. AND buyer.rowid = buy_order.ownership_id
  489. AND seller.rowid = sell_order.ownership_id
  490. AND buyer.ownable_id = ?
  491. AND seller.ownable_id = ?
  492. AND buy_order."limit" IS NOT NULL
  493. AND NOT buy_order.stop_loss
  494. AND sell_order."limit" IS NULL
  495. ORDER BY buy_order."limit" DESC,
  496. buy_order.rowid ASC,
  497. sell_order.rowid ASC
  498. LIMIT 1)
  499. UNION ALL -- both limit orders
  500. SELECT * FROM (
  501. SELECT buy_order.*, sell_order.*, buyer.user_id, seller.user_id, buy_order.rowid, sell_order.rowid
  502. FROM orders buy_order, orders sell_order, ownership buyer, ownership seller
  503. WHERE buy_order.buy AND NOT sell_order.buy
  504. AND buyer.rowid = buy_order.ownership_id
  505. AND seller.rowid = sell_order.ownership_id
  506. AND buyer.ownable_id = ?
  507. AND seller.ownable_id = ?
  508. AND buy_order."limit" IS NOT NULL
  509. AND sell_order."limit" IS NOT NULL
  510. AND sell_order."limit" <= buy_order."limit"
  511. AND NOT sell_order.stop_loss
  512. AND NOT buy_order.stop_loss
  513. ORDER BY buy_order."limit" DESC,
  514. sell_order."limit" ASC,
  515. buy_order.rowid ASC,
  516. sell_order.rowid ASC
  517. LIMIT 1)
  518. LIMIT 1
  519. ''', tuple(ownable_id for _ in range(8)))
  520. matching_orders = cursor.fetchone()
  521. # return type: (ownership_id,buy,limit,stop_loss,ordered_amount,executed_amount,expiry_dt,
  522. # ownership_id,buy,limit,stop_loss,ordered_amount,executed_amount,expiry_dt,
  523. # user_id,user_id,rowid,rowid)
  524. if not matching_orders:
  525. break
  526. buy_ownership_id, _, buy_limit, _, buy_order_amount, buy_executed_amount, buy_expiry_dt, \
  527. sell_ownership_id, _, sell_limit, _, sell_order_amount, sell_executed_amount, sell_expiry_dt, \
  528. buyer_id, seller_id, buy_order_id, sell_order_id \
  529. = matching_orders
  530. if buy_limit is None and sell_limit is None:
  531. price = current_value(ownable_id)
  532. elif buy_limit is None:
  533. price = sell_limit
  534. elif sell_limit is None:
  535. price = buy_limit
  536. else: # both not NULL
  537. # the price of the older order is used, just like in the real exchange
  538. if buy_order_id < sell_order_id:
  539. price = buy_limit
  540. else:
  541. price = sell_limit
  542. buyer_money = user_money(buyer_id)
  543. def _my_division(x, y):
  544. try:
  545. return floor(x/y)
  546. except ZeroDivisionError:
  547. return float('Inf')
  548. amount = min(buy_order_amount - buy_executed_amount,
  549. sell_order_amount - sell_executed_amount,
  550. _my_division(buyer_money, price))
  551. if amount == 0: # probable because buyer has not enough money
  552. delete_order(buy_order_id)
  553. continue
  554. buy_order_finished = (buy_order_amount - buy_executed_amount - amount <= 0) or (
  555. buyer_money - amount * price < price)
  556. sell_order_finished = (sell_order_amount - sell_executed_amount - amount <= 0)
  557. if price < 0 or amount <= 0: # price of 0 is possible though unlikely
  558. return AssertionError()
  559. # actually execute the order, but the bank does not send or receive anything
  560. if buyer_id != bank_id(): # buyer pays
  561. cursor.execute('''
  562. UPDATE ownership
  563. SET amount = amount - ?
  564. WHERE user_id = ?
  565. AND ownable_id = ?
  566. ''', (price * amount, buyer_id, currency_id()))
  567. if seller_id != bank_id(): # seller pays
  568. cursor.execute('''
  569. UPDATE ownership
  570. SET amount = amount - ?
  571. WHERE rowid = ?
  572. ''', (amount, sell_ownership_id))
  573. if buyer_id != bank_id(): # buyer receives
  574. cursor.execute('''
  575. UPDATE ownership
  576. SET amount = amount + ?
  577. WHERE rowid = ?
  578. ''', (amount, buy_ownership_id))
  579. if seller_id != bank_id(): # seller receives
  580. cursor.execute('''
  581. UPDATE ownership
  582. SET amount = amount + ?
  583. WHERE user_id = ?
  584. AND ownable_id = ?
  585. ''', (price * amount, seller_id, currency_id()))
  586. # update order execution state
  587. cursor.execute('''
  588. UPDATE orders
  589. SET executed_amount = executed_amount + ?
  590. WHERE rowid = ?
  591. OR rowid = ?
  592. ''', (amount, buy_order_id, sell_order_id))
  593. if buy_order_finished:
  594. delete_order(buy_order_id)
  595. if sell_order_finished:
  596. delete_order(sell_order_id)
  597. if seller_id != buyer_id: # prevent showing self-transactions
  598. cursor.execute('''
  599. INSERT INTO transactions
  600. (price, ownable_id, amount)
  601. VALUES(?, ?, ?)
  602. ''', (price, ownable_id, amount,))
  603. # trigger stop-loss orders
  604. if buyer_id != seller_id:
  605. # todo optimize this query, very slow like this
  606. cursor.execute('''
  607. UPDATE orders
  608. SET stop_loss = NULL,
  609. "limit" = NULL
  610. WHERE stop_loss IS NOT NULL
  611. AND stop_loss
  612. AND ? IN (SELECT ownable_id FROM ownership WHERE rowid = ownership_id)
  613. AND ((buy AND "limit" < ?) OR (NOT buy AND "limit" > ?))
  614. ''', (ownable_id, price, price,))
  615. def ownable_id_by_ownership_id(ownership_id):
  616. connect()
  617. cursor.execute('''
  618. SELECT ownable_id
  619. FROM ownership
  620. WHERE rowid = ?
  621. ''', (ownership_id,))
  622. return cursor.fetchone()[0]
  623. def ownable_name_by_id(ownable_id):
  624. connect()
  625. cursor.execute('''
  626. SELECT name
  627. FROM ownables
  628. WHERE rowid = ?
  629. ''', (ownable_id,))
  630. return cursor.fetchone()[0]
  631. def bank_order(buy, ownable_id, limit, amount, time_until_expiration):
  632. if not limit:
  633. raise AssertionError('The bank does not give away anything.')
  634. place_order(buy,
  635. get_ownership_id(ownable_id, bank_id()),
  636. limit,
  637. False,
  638. amount,
  639. time_until_expiration)
  640. ownable_name = ownable_name_by_id(ownable_id)
  641. new_news('External investors are selling ' + ownable_name + ' atm')
  642. def current_db_time(): # might differ from datetime.datetime.now() for time zone reasons
  643. connect()
  644. cursor.execute('''
  645. SELECT datetime('now')
  646. ''')
  647. return cursor.fetchone()[0]
  648. def place_order(buy, ownership_id, limit, stop_loss, amount, time_until_expiration):
  649. connect()
  650. expiry = datetime.strptime(current_db_time(), '%Y-%m-%d %H:%M:%S') + timedelta(minutes=time_until_expiration)
  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):
  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. ''', (ownable_id,))
  666. return cursor.fetchall()
  667. def drop_expired_orders():
  668. connect()
  669. cursor.execute('''
  670. DELETE FROM orders
  671. WHERE expiry_dt < DATETIME('now')
  672. ''')
  673. return cursor.fetchall()
  674. def generate_keys(count=1):
  675. # source https://stackoverflow.com/questions/17049308/python-3-3-serial-key-generator-list-problems
  676. for i in range(count):
  677. key = '-'.join(random_chars(5) for _ in range(5))
  678. save_key(key)
  679. print(key)
  680. def user_has_order_with_id(session_id, order_id):
  681. connect()
  682. cursor.execute('''
  683. SELECT orders.rowid
  684. FROM orders, ownership, sessions
  685. WHERE orders.rowid = ?
  686. AND sessions.session_id = ?
  687. AND sessions.user_id = ownership.user_id
  688. AND ownership.rowid = orders.ownership_id
  689. ''', (order_id, session_id,))
  690. if cursor.fetchone():
  691. return True
  692. else:
  693. return False
  694. def leaderboard():
  695. connect()
  696. cursor.execute('''
  697. SELECT *
  698. FROM ( -- one score for each user
  699. SELECT
  700. username,
  701. SUM(CASE -- sum score for each of the users ownables
  702. WHEN ownership.ownable_id = ? THEN ownership.amount
  703. ELSE ownership.amount * (SELECT price
  704. FROM transactions
  705. WHERE ownable_id = ownership.ownable_id
  706. ORDER BY rowid DESC -- equivalent to ordering by dt
  707. LIMIT 1)
  708. END
  709. ) score
  710. FROM users, ownership
  711. WHERE ownership.user_id = users.rowid
  712. AND users.username != 'bank'
  713. GROUP BY users.rowid
  714. ) AS scores
  715. ORDER BY score DESC
  716. LIMIT 50
  717. ''', (currency_id(),))
  718. return cursor.fetchall()
  719. def user_wealth(user_id):
  720. connect()
  721. cursor.execute('''
  722. SELECT SUM(
  723. CASE -- sum score for each of the users ownables
  724. WHEN ownership.ownable_id = ? THEN ownership.amount
  725. ELSE ownership.amount * (SELECT price
  726. FROM transactions
  727. WHERE ownable_id = ownership.ownable_id
  728. ORDER BY rowid DESC -- equivalent to ordering by dt
  729. LIMIT 1)
  730. END
  731. ) score
  732. FROM ownership
  733. WHERE ownership.user_id = ?
  734. ''', (currency_id(), user_id,))
  735. return cursor.fetchone()[0]
  736. def change_password(session_id, password):
  737. connect()
  738. cursor.execute('''
  739. UPDATE users
  740. SET password = ?
  741. WHERE rowid = (SELECT user_id FROM sessions WHERE sessions.session_id = ?)
  742. ''', (password, session_id,))
  743. def sign_out_user(session_id):
  744. connect()
  745. cursor.execute('''
  746. DELETE FROM sessions
  747. WHERE user_id = (SELECT user_id FROM sessions s2 WHERE s2.session_id = ?)
  748. ''', (session_id,))
  749. def delete_user(user_id):
  750. connect()
  751. cursor.execute('''
  752. DELETE FROM sessions
  753. WHERE user_id = ?
  754. ''', (user_id,))
  755. cursor.execute('''
  756. DELETE FROM orders
  757. WHERE ownership_id IN (
  758. SELECT rowid FROM ownership WHERE user_id = ?)
  759. ''', (user_id,))
  760. cursor.execute('''
  761. DELETE FROM ownership
  762. WHERE user_id = ?
  763. ''', (user_id,))
  764. cursor.execute('''
  765. DELETE FROM keys
  766. WHERE used_by_user_id = ?
  767. ''', (user_id,))
  768. cursor.execute('''
  769. INSERT INTO news(title)
  770. VALUES ((SELECT username FROM users WHERE rowid = ?) || ' retired.')
  771. ''', (user_id,))
  772. cursor.execute('''
  773. DELETE FROM users
  774. WHERE rowid = ?
  775. ''', (user_id,))
  776. def delete_ownable(ownable_id):
  777. connect()
  778. cursor.execute('''
  779. DELETE FROM transactions
  780. WHERE ownable_id = ?
  781. ''', (ownable_id,))
  782. cursor.execute('''
  783. DELETE FROM orders
  784. WHERE ownership_id IN (
  785. SELECT rowid FROM ownership WHERE ownable_id = ?)
  786. ''', (ownable_id,))
  787. # only delete empty ownerships
  788. cursor.execute('''
  789. DELETE FROM ownership
  790. WHERE ownable_id = ?
  791. AND amount = 0
  792. ''', (ownable_id,))
  793. cursor.execute('''
  794. INSERT INTO news(title)
  795. VALUES ((SELECT name FROM ownables WHERE rowid = ?) || ' can not be traded any more.')
  796. ''', (ownable_id,))
  797. cursor.execute('''
  798. DELETE FROM ownables
  799. WHERE rowid = ?
  800. ''', (ownable_id,))
  801. def hash_all_users_passwords():
  802. connect()
  803. cursor.execute('''
  804. SELECT rowid, password
  805. FROM users
  806. ''')
  807. users = cursor.fetchall()
  808. for user in users:
  809. user_id = user[0]
  810. pw = user[1]
  811. valid_hash = True
  812. try:
  813. sha256_crypt.verify('password' + salt, pw)
  814. except ValueError:
  815. valid_hash = False
  816. if valid_hash:
  817. raise AssertionError('There is already a hashed password in the database! Be careful what you are doing!')
  818. pw = sha256_crypt.encrypt(pw + salt)
  819. cursor.execute('''
  820. UPDATE users
  821. SET password = ?
  822. WHERE rowid = ?
  823. ''', (pw, user_id,))
  824. def new_news(message):
  825. connect()
  826. cursor.execute('''
  827. INSERT INTO news(title)
  828. VALUES (?)
  829. ''', (message,))