model.py 26 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724725726727728729730731732733734735736737738739740741742743744745746747748749750751752753754755756757758759760761762763764765766767768769770771772773774775776777778779780781782783784785786787788789790791792793794795796797798799800801802803804805806807808809810811812813814815816817818819820821822823824825826827828829830831832833834835836837838839840841842843844845846847848849850851852853854855856857858859860861862863864865866867868869870871872873874875876877878879880881882883884885886887888889890891892893894895896897898899900901902903904905906907908909910911912913914915916917918919920921922923924925926927928929930931932933934935936937938939940941942943944945946947948949950951952953954955956957958959960961962963964965966967968969970971972973974975976977978979980981982983984985986987988989990991992993994995996
  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. new_news('A new stock can now be bought: ' + name)
  382. if random.getrandbits(1):
  383. new_news('Experts expect the price of ' + name + ' to fall')
  384. else:
  385. new_news('Experts expect the price of ' + name + ' to rise')
  386. amount = random.randrange(100, 10000)
  387. price = random.randrange(10000, 20000) / amount
  388. ownable_id = ownable_id_by_name(name)
  389. own(bank_id(), name)
  390. bank_order(False,
  391. ownable_id,
  392. price,
  393. amount,
  394. timeout)
  395. return name
  396. def new_stocks(timeout=60, count=1):
  397. return [new_stock(timeout=timeout) for _ in range(count)]
  398. def ownable_id_by_name(ownable_name):
  399. connect()
  400. cursor.execute('''
  401. SELECT rowid
  402. FROM ownables
  403. WHERE name = ?
  404. ''', (ownable_name,))
  405. return cursor.fetchone()[0]
  406. def get_ownership_id(ownable_id, user_id):
  407. connect()
  408. cursor.execute('''
  409. SELECT rowid
  410. FROM ownership
  411. WHERE ownable_id = ?
  412. AND user_id = ?
  413. ''', (ownable_id, user_id,))
  414. return cursor.fetchone()[0]
  415. def currency_id():
  416. connect()
  417. cursor.execute('''
  418. SELECT rowid
  419. FROM ownables
  420. WHERE name = ?
  421. ''', (CURRENCY_NAME,))
  422. return cursor.fetchone()[0]
  423. def user_money(user_id):
  424. connect()
  425. cursor.execute('''
  426. SELECT amount
  427. FROM ownership
  428. WHERE user_id = ?
  429. AND ownable_id = ?
  430. ''', (user_id, currency_id()))
  431. return cursor.fetchone()[0]
  432. def delete_order(order_id):
  433. connect()
  434. cursor.execute('''
  435. DELETE FROM orders
  436. WHERE rowid = ?
  437. ''', (order_id,))
  438. def current_value(ownable_id):
  439. connect()
  440. cursor.execute('''SELECT price
  441. FROM transactions
  442. WHERE ownable_id = ?
  443. ORDER BY rowid DESC -- equivalent to order by dt
  444. LIMIT 1
  445. ''', (ownable_id,))
  446. return cursor.fetchone()[0]
  447. def execute_orders(ownable_id):
  448. connect()
  449. while True:
  450. # find order to execute
  451. cursor.execute('''
  452. SELECT buy_order.*, sell_order.*, buyer.user_id, seller.user_id, buy_order.rowid, sell_order.rowid
  453. FROM orders buy_order, orders sell_order, ownership buyer, ownership seller
  454. WHERE buy_order.buy AND NOT sell_order.buy
  455. AND buyer.rowid = buy_order.ownership_id
  456. AND seller.rowid = sell_order.ownership_id
  457. AND buyer.ownable_id = ?
  458. AND seller.ownable_id = ?
  459. AND (buy_order."limit" IS NULL
  460. OR sell_order."limit" IS NULL
  461. OR (sell_order."limit" <= buy_order."limit"
  462. AND NOT sell_order.stop_loss
  463. AND NOT buy_order.stop_loss))
  464. ORDER BY CASE WHEN sell_order."limit" IS NULL THEN 0 ELSE 1 END ASC,
  465. CASE WHEN buy_order."limit" IS NULL THEN 0 ELSE 1 END ASC,
  466. buy_order."limit" DESC,
  467. sell_order."limit" ASC,
  468. buy_order.ordered_amount - buy_order.executed_amount DESC,
  469. sell_order.ordered_amount - sell_order.executed_amount DESC
  470. LIMIT 1
  471. ''', (ownable_id, ownable_id,))
  472. matching_orders = cursor.fetchone()
  473. # return type: (ownership_id,buy,limit,stop_loss,ordered_amount,executed_amount,expiry_dt,
  474. # ownership_id,buy,limit,stop_loss,ordered_amount,executed_amount,expiry_dt,
  475. # user_id,user_id,rowid,rowid)
  476. if not matching_orders:
  477. break
  478. buy_ownership_id, _, buy_limit, _, buy_order_amount, buy_executed_amount, buy_expiry_dt, \
  479. sell_ownership_id, _, sell_limit, _, sell_order_amount, sell_executed_amount, sell_expiry_dt, \
  480. buyer_id, seller_id, buy_order_id, sell_order_id \
  481. = matching_orders
  482. if buy_limit is None and sell_limit is None:
  483. price = current_value(ownable_id)
  484. elif buy_limit is None:
  485. price = sell_limit
  486. elif sell_limit is None:
  487. price = buy_limit
  488. else: # both not NULL
  489. # that is not how it works at the real exchange, the price of the older order is used
  490. price = (float(sell_limit) + float(buy_limit)) / 2
  491. buyer_money = user_money(buyer_id)
  492. amount = min(buy_order_amount - buy_executed_amount,
  493. sell_order_amount - sell_executed_amount,
  494. floor(buyer_money / price))
  495. if amount == 0: # probable because buyer has not enough money
  496. delete_order(buy_order_id)
  497. continue
  498. buy_order_finished = (buy_order_amount - buy_executed_amount - amount <= 0) or (
  499. buyer_money - amount * price < price)
  500. sell_order_finished = (sell_order_amount - sell_executed_amount - amount <= 0)
  501. if price < 0 or amount <= 0: # price of 0 is possible though unlikely
  502. return AssertionError()
  503. # actually execute the order, but the bank does not send or receive anything
  504. if buyer_id != bank_id(): # buyer pays
  505. cursor.execute('''
  506. UPDATE ownership
  507. SET amount = amount - ?
  508. WHERE user_id = ?
  509. AND ownable_id = ?
  510. ''', (price * amount, buyer_id, currency_id()))
  511. if seller_id != bank_id(): # seller pays
  512. cursor.execute('''
  513. UPDATE ownership
  514. SET amount = amount - ?
  515. WHERE rowid = ?
  516. ''', (amount, sell_ownership_id))
  517. if buyer_id != bank_id(): # buyer receives
  518. cursor.execute('''
  519. UPDATE ownership
  520. SET amount = amount + ?
  521. WHERE rowid = ?
  522. ''', (amount, buy_ownership_id))
  523. if seller_id != bank_id(): # seller receives
  524. cursor.execute('''
  525. UPDATE ownership
  526. SET amount = amount + ?
  527. WHERE user_id = ?
  528. AND ownable_id = ?
  529. ''', (price * amount, seller_id, currency_id()))
  530. # update order execution state
  531. cursor.execute('''
  532. UPDATE orders
  533. SET executed_amount = executed_amount + ?
  534. WHERE rowid = ?
  535. OR rowid = ?
  536. ''', (amount, buy_order_id, sell_order_id))
  537. if buy_order_finished:
  538. delete_order(buy_order_id)
  539. if sell_order_finished:
  540. delete_order(sell_order_id)
  541. if seller_id != buyer_id: # prevent showing self-transactions
  542. cursor.execute('''
  543. INSERT INTO transactions
  544. (price, ownable_id, amount)
  545. VALUES(?, ?, ?)
  546. ''', (price, ownable_id, amount,))
  547. # trigger stop-loss orders
  548. if buyer_id != seller_id:
  549. # todo optimize this query, very slow like this
  550. cursor.execute('''
  551. UPDATE orders
  552. SET stop_loss = NULL,
  553. "limit" = NULL
  554. WHERE stop_loss IS NOT NULL
  555. AND stop_loss
  556. AND ? IN (SELECT ownable_id FROM ownership WHERE rowid = ownership_id)
  557. AND ((buy AND "limit" < ?) OR (NOT buy AND "limit" > ?))
  558. ''', (ownable_id, price, price,))
  559. def ownable_id_by_ownership_id(ownership_id):
  560. connect()
  561. cursor.execute('''
  562. SELECT ownable_id
  563. FROM ownership
  564. WHERE rowid = ?
  565. ''', (ownership_id,))
  566. return cursor.fetchone()[0]
  567. def ownable_name_by_id(ownable_id):
  568. connect()
  569. cursor.execute('''
  570. SELECT name
  571. FROM ownables
  572. WHERE rowid = ?
  573. ''', (ownable_id,))
  574. return cursor.fetchone()[0]
  575. def bank_order(buy, ownable_id, limit, amount, time_until_expiration):
  576. if not limit:
  577. raise AssertionError('The bank does not give away anything.')
  578. place_order(buy,
  579. get_ownership_id(ownable_id, bank_id()),
  580. limit,
  581. False,
  582. amount,
  583. time_until_expiration)
  584. ownable_name = ownable_name_by_id(ownable_id)
  585. new_news('External investors are selling ' + ownable_name + ' atm')
  586. def current_db_time(): # might differ from datetime.datetime.now() for time zone reasons
  587. connect()
  588. cursor.execute('''
  589. SELECT datetime('now')
  590. ''')
  591. return cursor.fetchone()[0]
  592. def place_order(buy, ownership_id, limit, stop_loss, amount, time_until_expiration):
  593. connect()
  594. expiry = datetime.strptime(current_db_time(), '%Y-%m-%d %H:%M:%S') + timedelta(minutes=time_until_expiration)
  595. cursor.execute('''
  596. INSERT INTO orders
  597. (buy, ownership_id, "limit", stop_loss, ordered_amount, expiry_dt)
  598. VALUES (?, ?, ?, ?, ?, ?)
  599. ''', (buy, ownership_id, limit, stop_loss, amount, expiry))
  600. execute_orders(ownable_id_by_ownership_id(ownership_id))
  601. return True
  602. def transactions(ownable_id):
  603. connect()
  604. cursor.execute('''
  605. SELECT dt, amount, price
  606. FROM transactions
  607. WHERE ownable_id = ?
  608. ORDER BY rowid DESC -- equivalent to order by dt
  609. ''', (ownable_id,))
  610. return cursor.fetchall()
  611. def drop_expired_orders():
  612. connect()
  613. cursor.execute('''
  614. DELETE FROM orders
  615. WHERE expiry_dt < DATETIME('now')
  616. ''')
  617. return cursor.fetchall()
  618. def generate_keys(count=1):
  619. # source https://stackoverflow.com/questions/17049308/python-3-3-serial-key-generator-list-problems
  620. for i in range(count):
  621. key = '-'.join(random_chars(5) for _ in range(5))
  622. save_key(key)
  623. print(key)
  624. def user_has_order_with_id(session_id, order_id):
  625. connect()
  626. cursor.execute('''
  627. SELECT orders.rowid
  628. FROM orders, ownership, sessions
  629. WHERE orders.rowid = ?
  630. AND sessions.session_id = ?
  631. AND sessions.user_id = ownership.user_id
  632. AND ownership.rowid = orders.ownership_id
  633. ''', (order_id, session_id,))
  634. if cursor.fetchone():
  635. return True
  636. else:
  637. return False
  638. def leaderboard():
  639. connect()
  640. cursor.execute('''
  641. SELECT *
  642. FROM ( -- one score for each user
  643. SELECT
  644. username,
  645. SUM(CASE -- sum score for each of the users ownables
  646. WHEN ownership.ownable_id = ? THEN ownership.amount
  647. ELSE ownership.amount * (SELECT price
  648. FROM transactions
  649. WHERE ownable_id = ownership.ownable_id
  650. ORDER BY rowid DESC -- equivalent to ordering by dt
  651. LIMIT 1)
  652. END
  653. ) score
  654. FROM users, ownership
  655. WHERE ownership.user_id = users.rowid
  656. AND users.username != 'bank'
  657. GROUP BY users.rowid
  658. ) AS scores
  659. ORDER BY score DESC
  660. LIMIT 50
  661. ''', (currency_id(),))
  662. return cursor.fetchall()
  663. def user_wealth(user_id):
  664. connect()
  665. cursor.execute('''
  666. SELECT SUM(
  667. CASE -- sum score for each of the users ownables
  668. WHEN ownership.ownable_id = ? THEN ownership.amount
  669. ELSE ownership.amount * (SELECT price
  670. FROM transactions
  671. WHERE ownable_id = ownership.ownable_id
  672. ORDER BY rowid DESC -- equivalent to ordering by dt
  673. LIMIT 1)
  674. END
  675. ) score
  676. FROM ownership
  677. WHERE ownership.user_id = ?
  678. ''', (currency_id(), user_id,))
  679. return cursor.fetchone()[0]
  680. def change_password(session_id, password):
  681. connect()
  682. cursor.execute('''
  683. UPDATE users
  684. SET password = ?
  685. WHERE rowid = (SELECT user_id FROM sessions WHERE sessions.session_id = ?)
  686. ''', (password, session_id,))
  687. def sign_out_user(session_id):
  688. connect()
  689. cursor.execute('''
  690. DELETE FROM sessions
  691. WHERE user_id = (SELECT user_id FROM sessions s2 WHERE s2.session_id = ?)
  692. ''', (session_id,))
  693. def delete_user(user_id):
  694. connect()
  695. cursor.execute('''
  696. DELETE FROM sessions
  697. WHERE user_id = ?
  698. ''', (user_id,))
  699. cursor.execute('''
  700. DELETE FROM orders
  701. WHERE ownership_id IN (
  702. SELECT rowid FROM ownership WHERE user_id = ?)
  703. ''', (user_id,))
  704. cursor.execute('''
  705. DELETE FROM ownership
  706. WHERE user_id = ?
  707. ''', (user_id,))
  708. cursor.execute('''
  709. DELETE FROM keys
  710. WHERE used_by_user_id = ?
  711. ''', (user_id,))
  712. cursor.execute('''
  713. INSERT INTO news(title)
  714. VALUES ((SELECT username FROM users WHERE rowid = ?) || ' retired.')
  715. ''', (user_id,))
  716. cursor.execute('''
  717. DELETE FROM users
  718. WHERE rowid = ?
  719. ''', (user_id,))
  720. def delete_ownable(ownable_id):
  721. connect()
  722. cursor.execute('''
  723. DELETE FROM transactions
  724. WHERE ownable_id = ?
  725. ''', (ownable_id,))
  726. cursor.execute('''
  727. DELETE FROM orders
  728. WHERE ownership_id IN (
  729. SELECT rowid FROM ownership WHERE ownable_id = ?)
  730. ''', (ownable_id,))
  731. # only delete empty ownerships
  732. cursor.execute('''
  733. DELETE FROM ownership
  734. WHERE ownable_id = ?
  735. AND amount = 0
  736. ''', (ownable_id,))
  737. cursor.execute('''
  738. INSERT INTO news(title)
  739. VALUES ((SELECT name FROM ownables WHERE rowid = ?) || ' can not be traded any more.')
  740. ''', (ownable_id,))
  741. cursor.execute('''
  742. DELETE FROM ownables
  743. WHERE rowid = ?
  744. ''', (ownable_id,))
  745. def hash_all_users_passwords():
  746. connect()
  747. cursor.execute('''
  748. SELECT rowid, password
  749. FROM users
  750. ''')
  751. users = cursor.fetchall()
  752. for user in users:
  753. user_id = user[0]
  754. pw = user[1]
  755. valid_hash = True
  756. try:
  757. sha256_crypt.verify('password' + salt, pw)
  758. except ValueError:
  759. valid_hash = False
  760. if valid_hash:
  761. raise AssertionError('There is already a hashed password in the database! Be careful what you are doing!')
  762. pw = sha256_crypt.encrypt(pw + salt)
  763. cursor.execute('''
  764. UPDATE users
  765. SET password = ?
  766. WHERE rowid = ?
  767. ''', (pw, user_id,))
  768. def new_news(message):
  769. connect()
  770. cursor.execute('''
  771. INSERT INTO news(title)
  772. VALUES (?)
  773. ''', (message,))