model.py 27 KB

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