model.py 27 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724725726727728729730731732733734735736737738739740741742743744745746747748749750751752753754755756757758759760761762763764765766767768769770771772773774775776777778779780781782783784785786787788789790791792793794795796797798799800801802803804805806807808809810811812813814815816817818819820821822823824825826827828829830831832833834835836837838839840841842843844845846847848849850851852853854855856857858859860861862863864865866867868869870871872873874875876877878879880881882883884885886887888889890891892893894895896897898899900901902903904905906907908909910911912913914915916917918919920921922923924925926927928929930931932933934935936937938939940941942943944945946947948949950951952953954955956957958959960961962963964965966967968969970971972973974975976977978979980981982983984985986987988989990991992993994995996997998999100010011002
  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. ''', (ownable_name, user_id,))
  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. ''', (currency_id(), user_id, currency_id(),))
  234. return cursor.fetchall()
  235. def activate_key(key, user_id):
  236. connect()
  237. cursor.execute('''
  238. UPDATE keys
  239. SET used_by_user_id = ?
  240. WHERE used_by_user_id IS NULL
  241. AND key = ?
  242. ''', (user_id, key,))
  243. send_ownable(bank_id(), user_id, CURRENCY_NAME, 1000)
  244. def bank_id():
  245. connect()
  246. cursor.execute('''
  247. SELECT users.rowid
  248. FROM users
  249. WHERE username = 'bank'
  250. ''')
  251. return cursor.fetchone()[0]
  252. def valid_session_id(session_id):
  253. connect()
  254. cursor.execute('''
  255. SELECT rowid
  256. FROM sessions
  257. WHERE session_id = ?
  258. ''', (session_id,))
  259. if cursor.fetchone():
  260. return True
  261. else:
  262. return False
  263. def get_user_orders(user_id):
  264. connect()
  265. cursor.execute('''
  266. SELECT
  267. CASE
  268. WHEN orders.buy THEN 'Buy'
  269. ELSE 'Sell'
  270. END,
  271. ownables.name,
  272. (orders.ordered_amount - orders.executed_amount) || '/' || orders.ordered_amount,
  273. orders."limit",
  274. CASE
  275. WHEN orders."limit" IS NULL THEN NULL
  276. WHEN orders.stop_loss THEN 'Yes'
  277. ELSE 'No'
  278. END,
  279. datetime(orders.expiry_dt),
  280. orders.rowid
  281. FROM orders, ownables, ownership
  282. WHERE ownership.user_id = ?
  283. AND ownership.ownable_id = ownables.rowid
  284. AND orders.ownership_id = ownership.rowid
  285. ORDER BY ownables.name ASC, orders.stop_loss ASC, orders.buy DESC, orders."limit" ASC
  286. ''', (user_id,))
  287. return cursor.fetchall()
  288. def get_ownable_orders(ownable_id):
  289. connect()
  290. cursor.execute('''
  291. SELECT
  292. CASE
  293. WHEN orders.buy THEN 'Buy'
  294. ELSE 'Sell'
  295. END,
  296. ownables.name,
  297. orders.ordered_amount - orders.executed_amount,
  298. orders."limit",
  299. CASE
  300. WHEN orders."limit" IS NULL THEN NULL
  301. WHEN orders.stop_loss THEN 'Yes'
  302. ELSE 'No'
  303. END,
  304. datetime(orders.expiry_dt),
  305. orders.rowid
  306. FROM orders, ownables, ownership
  307. WHERE ownership.ownable_id = ?
  308. AND ownership.ownable_id = ownables.rowid
  309. AND orders.ownership_id = ownership.rowid
  310. ORDER BY ownables.name ASC, orders.stop_loss ASC, orders.buy DESC, orders."limit" ASC
  311. ''', (ownable_id,))
  312. return cursor.fetchall()
  313. def sell_ordered_amount(user_id, ownable_id):
  314. connect()
  315. cursor.execute('''
  316. SELECT COALESCE(SUM(orders.ordered_amount - orders.executed_amount),0)
  317. FROM orders, ownership
  318. WHERE ownership.rowid = orders.ownership_id
  319. AND ownership.user_id = ?
  320. AND ownership.ownable_id = ?
  321. AND NOT orders.buy
  322. ''', (user_id, ownable_id))
  323. return cursor.fetchone()[0]
  324. def available_amount(user_id, ownable_id):
  325. connect()
  326. cursor.execute('''
  327. SELECT amount
  328. FROM ownership
  329. WHERE user_id = ?
  330. AND ownable_id = ?
  331. ''', (user_id, ownable_id))
  332. return cursor.fetchone()[0] - sell_ordered_amount(user_id, ownable_id)
  333. def user_owns_at_least(amount, user_id, ownable_id):
  334. connect()
  335. if not isinstance(amount, float) and not isinstance(amount, int):
  336. # comparison of float with strings does not work so well in sql
  337. raise AssertionError()
  338. cursor.execute('''
  339. SELECT rowid
  340. FROM ownership
  341. WHERE user_id = ?
  342. AND ownable_id = ?
  343. AND amount - ? >= ?
  344. ''', (user_id, ownable_id, sell_ordered_amount(user_id, ownable_id), amount))
  345. if cursor.fetchone():
  346. return True
  347. else:
  348. return False
  349. def news():
  350. connect()
  351. cursor.execute('''
  352. SELECT * FROM
  353. (SELECT *
  354. FROM news
  355. ORDER BY rowid DESC -- equivalent to order by dt
  356. LIMIT 20) n
  357. ORDER BY dt ASC
  358. ''')
  359. return cursor.fetchall()
  360. def ownable_name_exists(name):
  361. connect()
  362. cursor.execute('''
  363. SELECT rowid
  364. FROM ownables
  365. WHERE name = ?
  366. ''', (name,))
  367. if cursor.fetchone():
  368. return True
  369. else:
  370. return False
  371. def new_stock(timeout=60, name=None):
  372. connect()
  373. while name is None:
  374. name = random_chars(6)
  375. if ownable_name_exists(name):
  376. name = None
  377. cursor.execute('''
  378. INSERT INTO ownables(name)
  379. VALUES (?)
  380. ''', (name,))
  381. cursor.execute('''
  382. INSERT INTO news(title)
  383. VALUES (?)
  384. ''', ('A new stock can now be bought: ' + name,))
  385. if random.getrandbits(1):
  386. cursor.execute('''
  387. INSERT INTO news(title)
  388. VALUES (?)
  389. ''', ('Experts expect the price of ' + name + ' to fall',))
  390. else:
  391. cursor.execute('''
  392. INSERT INTO news(title)
  393. VALUES (?)
  394. ''', ('Experts expect the price of ' + name + ' to rise',))
  395. amount = random.randrange(100, 10000)
  396. price = random.randrange(10000, 20000) / amount
  397. ownable_id = ownable_id_by_name(name)
  398. own(bank_id(), name)
  399. bank_order(False,
  400. ownable_id,
  401. price,
  402. amount,
  403. timeout)
  404. return name
  405. def new_stocks(timeout=60, count=1):
  406. return [new_stock(timeout=timeout) for _ in range(count)]
  407. def ownable_id_by_name(ownable_name):
  408. connect()
  409. cursor.execute('''
  410. SELECT rowid
  411. FROM ownables
  412. WHERE name = ?
  413. ''', (ownable_name,))
  414. return cursor.fetchone()[0]
  415. def get_ownership_id(ownable_id, user_id):
  416. connect()
  417. cursor.execute('''
  418. SELECT rowid
  419. FROM ownership
  420. WHERE ownable_id = ?
  421. AND user_id = ?
  422. ''', (ownable_id, user_id,))
  423. return cursor.fetchone()[0]
  424. def currency_id():
  425. connect()
  426. cursor.execute('''
  427. SELECT rowid
  428. FROM ownables
  429. WHERE name = ?
  430. ''', (CURRENCY_NAME,))
  431. return cursor.fetchone()[0]
  432. def user_money(user_id):
  433. connect()
  434. cursor.execute('''
  435. SELECT amount
  436. FROM ownership
  437. WHERE user_id = ?
  438. AND ownable_id = ?
  439. ''', (user_id, currency_id()))
  440. return cursor.fetchone()[0]
  441. def delete_order(order_id):
  442. connect()
  443. cursor.execute('''
  444. DELETE FROM orders
  445. WHERE rowid = ?
  446. ''', (order_id,))
  447. def current_value(ownable_id):
  448. connect()
  449. cursor.execute('''SELECT price
  450. FROM transactions
  451. WHERE ownable_id = ?
  452. ORDER BY rowid DESC -- equivalent to order by dt
  453. LIMIT 1
  454. ''', (ownable_id,))
  455. return cursor.fetchone()[0]
  456. def execute_orders(ownable_id):
  457. connect()
  458. while True:
  459. # find order to execute
  460. cursor.execute('''
  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. OR sell_order."limit" IS NULL
  470. OR (sell_order."limit" <= buy_order."limit"
  471. AND NOT sell_order.stop_loss
  472. AND NOT buy_order.stop_loss))
  473. ORDER BY CASE WHEN sell_order."limit" IS NULL THEN 0 ELSE 1 END ASC,
  474. CASE WHEN buy_order."limit" IS NULL THEN 0 ELSE 1 END ASC,
  475. buy_order."limit" DESC,
  476. sell_order."limit" ASC,
  477. buy_order.ordered_amount - buy_order.executed_amount DESC,
  478. sell_order.ordered_amount - sell_order.executed_amount DESC
  479. LIMIT 1
  480. ''', (ownable_id, ownable_id,))
  481. matching_orders = cursor.fetchone()
  482. # return type: (ownership_id,buy,limit,stop_loss,ordered_amount,executed_amount,expiry_dt,
  483. # ownership_id,buy,limit,stop_loss,ordered_amount,executed_amount,expiry_dt,
  484. # user_id,user_id,rowid,rowid)
  485. if not matching_orders:
  486. break
  487. buy_ownership_id, _, buy_limit, _, buy_order_amount, buy_executed_amount, buy_expiry_dt, \
  488. sell_ownership_id, _, sell_limit, _, sell_order_amount, sell_executed_amount, sell_expiry_dt, \
  489. buyer_id, seller_id, buy_order_id, sell_order_id \
  490. = matching_orders
  491. if buy_limit is None and sell_limit is None:
  492. price = current_value(ownable_id)
  493. elif buy_limit is None:
  494. price = sell_limit
  495. elif sell_limit is None:
  496. price = buy_limit
  497. else: # both not NULL
  498. price = (float(sell_limit) + float(buy_limit)) / 2
  499. if price == 0:
  500. raise AssertionError()
  501. buyer_money = user_money(buyer_id)
  502. amount = min(buy_order_amount - buy_executed_amount,
  503. sell_order_amount - sell_executed_amount,
  504. floor(buyer_money / price))
  505. if amount == 0: # probable because buyer has not enough money
  506. delete_order(buy_order_id)
  507. continue
  508. buy_order_finished = (buy_order_amount - buy_executed_amount - amount <= 0) or (
  509. buyer_money - amount * price < price)
  510. sell_order_finished = (sell_order_amount - sell_executed_amount - amount <= 0)
  511. if price < 0 or amount <= 0:
  512. return AssertionError()
  513. # actually execute the order, but the bank does not send or receive anything
  514. if buyer_id != bank_id(): # buyer pays
  515. cursor.execute('''
  516. UPDATE ownership
  517. SET amount = amount - ?
  518. WHERE user_id = ?
  519. AND ownable_id = ?
  520. ''', (price * amount, buyer_id, currency_id()))
  521. if seller_id != bank_id(): # seller pays
  522. cursor.execute('''
  523. UPDATE ownership
  524. SET amount = amount - ?
  525. WHERE rowid = ?
  526. ''', (amount, sell_ownership_id))
  527. if buyer_id != bank_id(): # buyer receives
  528. cursor.execute('''
  529. UPDATE ownership
  530. SET amount = amount + ?
  531. WHERE rowid = ?
  532. ''', (amount, buy_ownership_id))
  533. if seller_id != bank_id(): # seller receives
  534. cursor.execute('''
  535. UPDATE ownership
  536. SET amount = amount + ?
  537. WHERE user_id = ?
  538. AND ownable_id = ?
  539. ''', (price * amount, seller_id, currency_id()))
  540. # update order execution state
  541. cursor.execute('''
  542. UPDATE orders
  543. SET executed_amount = executed_amount + ?
  544. WHERE rowid = ?
  545. OR rowid = ?
  546. ''', (amount, buy_order_id, sell_order_id))
  547. if buy_order_finished:
  548. delete_order(buy_order_id)
  549. if sell_order_finished:
  550. delete_order(sell_order_id)
  551. if seller_id != buyer_id: # prevent showing self-transactions
  552. cursor.execute('''
  553. INSERT INTO transactions
  554. (price, ownable_id, amount)
  555. VALUES(?, ?, ?)
  556. ''', (price, ownable_id, amount,))
  557. # trigger stop-loss orders
  558. if buyer_id != seller_id:
  559. # todo optimize this query, very slow like this
  560. cursor.execute('''
  561. UPDATE orders
  562. SET stop_loss = NULL,
  563. "limit" = NULL
  564. WHERE stop_loss IS NOT NULL
  565. AND stop_loss
  566. AND ? IN (SELECT ownable_id FROM ownership WHERE rowid = ownership_id)
  567. AND ((buy AND "limit" < ?) OR (NOT buy AND "limit" > ?))
  568. ''', (ownable_id, price, price,))
  569. def ownable_id_by_ownership_id(ownership_id):
  570. connect()
  571. cursor.execute('''
  572. SELECT ownable_id
  573. FROM ownership
  574. WHERE rowid = ?
  575. ''', (ownership_id,))
  576. return cursor.fetchone()[0]
  577. def ownable_name_by_id(ownable_id):
  578. connect()
  579. cursor.execute('''
  580. SELECT name
  581. FROM ownables
  582. WHERE rowid = ?
  583. ''', (ownable_id,))
  584. return cursor.fetchone()[0]
  585. def bank_order(buy, ownable_id, limit, amount, time_until_expiration):
  586. if not limit:
  587. raise AssertionError('The bank does not give away anything.')
  588. place_order(buy,
  589. get_ownership_id(ownable_id, bank_id()),
  590. limit,
  591. False,
  592. amount,
  593. time_until_expiration)
  594. ownable_name = ownable_name_by_id(ownable_id)
  595. cursor.execute('''
  596. INSERT INTO news(title)
  597. VALUES (?)
  598. ''', ('External investors are selling ' + ownable_name + ' atm',))
  599. def current_db_time(): # might differ from datetime.datetime.now() for time zone reasons
  600. connect()
  601. cursor.execute('''
  602. SELECT datetime('now')
  603. ''')
  604. return cursor.fetchone()[0]
  605. def place_order(buy, ownership_id, limit, stop_loss, amount, time_until_expiration):
  606. connect()
  607. expiry = datetime.strptime(current_db_time(), '%Y-%m-%d %H:%M:%S') + timedelta(minutes=time_until_expiration)
  608. cursor.execute('''
  609. INSERT INTO orders
  610. (buy, ownership_id, "limit", stop_loss, ordered_amount, expiry_dt)
  611. VALUES (?, ?, ?, ?, ?, ?)
  612. ''', (buy, ownership_id, limit, stop_loss, amount, expiry))
  613. execute_orders(ownable_id_by_ownership_id(ownership_id))
  614. return True
  615. def transactions(ownable_id):
  616. connect()
  617. cursor.execute('''
  618. SELECT dt, amount, price
  619. FROM transactions
  620. WHERE ownable_id = ?
  621. ORDER BY rowid DESC -- equivalent to order by dt
  622. ''', (ownable_id,))
  623. return cursor.fetchall()
  624. def drop_expired_orders():
  625. connect()
  626. cursor.execute('''
  627. DELETE FROM orders
  628. WHERE expiry_dt < DATETIME('now')
  629. ''')
  630. return cursor.fetchall()
  631. def generate_keys(count=1):
  632. # source https://stackoverflow.com/questions/17049308/python-3-3-serial-key-generator-list-problems
  633. for i in range(count):
  634. key = '-'.join(random_chars(5) for _ in range(5))
  635. save_key(key)
  636. print(key)
  637. def user_has_order_with_id(session_id, order_id):
  638. connect()
  639. cursor.execute('''
  640. SELECT orders.rowid
  641. FROM orders, ownership, sessions
  642. WHERE orders.rowid = ?
  643. AND sessions.session_id = ?
  644. AND sessions.user_id = ownership.user_id
  645. AND ownership.rowid = orders.ownership_id
  646. ''', (order_id, session_id,))
  647. if cursor.fetchone():
  648. return True
  649. else:
  650. return False
  651. def leaderboard():
  652. connect()
  653. cursor.execute('''
  654. SELECT *
  655. FROM ( -- one score for each user
  656. SELECT
  657. username,
  658. SUM(CASE -- sum score for each of the users ownables
  659. WHEN ownership.ownable_id = ? THEN ownership.amount
  660. ELSE ownership.amount * (SELECT price
  661. FROM transactions
  662. WHERE ownable_id = ownership.ownable_id
  663. ORDER BY rowid DESC -- equivalent to ordering by dt
  664. LIMIT 1)
  665. END
  666. ) score
  667. FROM users, ownership
  668. WHERE ownership.user_id = users.rowid
  669. AND users.username != 'bank'
  670. GROUP BY users.rowid
  671. ) AS scores
  672. ORDER BY score DESC
  673. LIMIT 50
  674. ''', (currency_id(),))
  675. return cursor.fetchall()
  676. def user_wealth(user_id):
  677. connect()
  678. cursor.execute('''
  679. SELECT SUM(
  680. CASE -- sum score for each of the users ownables
  681. WHEN ownership.ownable_id = ? THEN ownership.amount
  682. ELSE ownership.amount * (SELECT price
  683. FROM transactions
  684. WHERE ownable_id = ownership.ownable_id
  685. ORDER BY rowid DESC -- equivalent to ordering by dt
  686. LIMIT 1)
  687. END
  688. ) score
  689. FROM ownership
  690. WHERE ownership.user_id = ?
  691. ''', (currency_id(), user_id,))
  692. return cursor.fetchone()[0]
  693. def change_password(session_id, password):
  694. connect()
  695. cursor.execute('''
  696. UPDATE users
  697. SET password = ?
  698. WHERE rowid = (SELECT user_id FROM sessions WHERE sessions.session_id = ?)
  699. ''', (password, session_id,))
  700. def sign_out_user(session_id):
  701. connect()
  702. cursor.execute('''
  703. DELETE FROM sessions
  704. WHERE user_id = (SELECT user_id FROM sessions s2 WHERE s2.session_id = ?)
  705. ''', (session_id,))
  706. def delete_user(user_id):
  707. connect()
  708. cursor.execute('''
  709. DELETE FROM sessions
  710. WHERE user_id = ?
  711. ''', (user_id,))
  712. cursor.execute('''
  713. DELETE FROM orders
  714. WHERE ownership_id IN (
  715. SELECT rowid FROM ownership WHERE user_id = ?)
  716. ''', (user_id,))
  717. cursor.execute('''
  718. DELETE FROM ownership
  719. WHERE user_id = ?
  720. ''', (user_id,))
  721. cursor.execute('''
  722. DELETE FROM keys
  723. WHERE used_by_user_id = ?
  724. ''', (user_id,))
  725. cursor.execute('''
  726. INSERT INTO news(title)
  727. VALUES ((SELECT username FROM users WHERE rowid = ?) || ' retired.')
  728. ''', (user_id,))
  729. cursor.execute('''
  730. DELETE FROM users
  731. WHERE rowid = ?
  732. ''', (user_id,))
  733. def delete_ownable(ownable_id):
  734. connect()
  735. cursor.execute('''
  736. DELETE FROM transactions
  737. WHERE ownable_id = ?
  738. ''', (ownable_id,))
  739. cursor.execute('''
  740. DELETE FROM orders
  741. WHERE ownership_id IN (
  742. SELECT rowid FROM ownership WHERE ownable_id = ?)
  743. ''', (ownable_id,))
  744. # only delete empty ownerships
  745. cursor.execute('''
  746. DELETE FROM ownership
  747. WHERE ownable_id = ?
  748. AND amount = 0
  749. ''', (ownable_id,))
  750. cursor.execute('''
  751. INSERT INTO news(title)
  752. VALUES ((SELECT name FROM ownables WHERE rowid = ?) || ' can not be traded any more.')
  753. ''', (ownable_id,))
  754. cursor.execute('''
  755. DELETE FROM ownables
  756. WHERE rowid = ?
  757. ''', (ownable_id,))
  758. def hash_all_users_passwords():
  759. connect()
  760. cursor.execute('''
  761. SELECT rowid, password
  762. FROM users
  763. ''')
  764. users = cursor.fetchall()
  765. for user in users:
  766. user_id = user[0]
  767. pw = user[1]
  768. valid_hash = True
  769. try:
  770. sha256_crypt.verify('password' + salt, pw)
  771. except ValueError:
  772. valid_hash = False
  773. if valid_hash:
  774. raise AssertionError('There is already a hashed password in the database! Be careful what you are doing!')
  775. pw = sha256_crypt.encrypt(pw + salt)
  776. cursor.execute('''
  777. UPDATE users
  778. SET password = ?
  779. WHERE rowid = ?
  780. ''', (pw, user_id,))