database.py 22 KB

123456789101112131415161718192021222324252627282930313233343536373839404142434445464748495051525354555657585960616263646566676869707172737475767778798081828384858687888990919293949596979899100101102103104105106107108109110111112113114115116117118119120121122123124125126127128129130131132133134135136137138139140141142143144145146147148149150151152153154155156157158159160161162163164165166167168169170171172173174175176177178179180181182183184185186187188189190191192193194195196197198199200201202203204205206207208209210211212213214215216217218219220221222223224225226227228229230231232233234235236237238239240241242243244245246247248249250251252253254255256257258259260261262263264265266267268269270271272273274275276277278279280281282283284285286287288289290291292293294295296297298299300301302303304305306307308309310311312313314315316317318319320321322323324325326327328329330331332333334335336337338339340341342343344345346347348349350351352353354355356357358359360361362363364365366367368369370371372373374375376377378379380381382383384385386387388389390391392393394395396397398399400401402403404405406407408409410411412413414415416417418419420421422423424425426427428429430431432433434435436437438439440441442443444445446447448449450451452453454455456457458459460461462463464465466467468469470471472473474475476477478479480481482483484485486487488489490491492493494495496497498499500501502503504505506507508509510511512513514515516517518519520521522523524525526527528529530531532533534535536537538539540541542543544545546547548549550551552553554555556557558559560561562563564565566567568569570571572573574575576577578579580581582583584585586587588589590591592593594595596597598599600601602603604605606607608609610611612613614615616617618619620621622623624625626627628629630631632633634635636637638639640641642643644645646647648649650651652653654655656657658659660661662663664665666667668669670671672673674675676677678679680681682683684685686687688689690691692693694695696697698699700701702703704705706707708709710711712713714715716717718719720721722723724725726727728729730731732733734735736737738739740741742743744745746747748749750751752753754755756757758759760761762763764765766767768769770771772773774775776777778779780781782783784785786787788789790791792793794795796797798799800801802803804805806807808809810811812813814815
  1. import hashlib
  2. import re
  3. import sqlite3
  4. from freepost import random, settings
  5. db = sqlite3.connect(settings['sqlite']['database'])
  6. # Returns SQLite rows as dictionaries instead of tuples.
  7. # https://docs.python.org/3/library/sqlite3.html#sqlite3.Connection.row_factory
  8. db.row_factory = sqlite3.Row
  9. # A custom function to compute SHA-512 because it's not built into SQLite
  10. db.create_function('SHA512', 1, lambda text:
  11. None if text is None else hashlib.sha512(text.encode('UTF-8')).hexdigest())
  12. # The REGEXP operator is a special syntax for the regexp() user function. No
  13. # regexp() user function is defined by default and so use of the REGEXP operator
  14. # will normally result in an error message. If an application-defined SQL
  15. # function named "regexp" is added at run-time, then the "X REGEXP Y" operator
  16. # will be implemented as a call to "regexp(Y,X)".
  17. db.create_function('REGEXP', 2, lambda pattern, string:
  18. re.search(pattern, string, flags=re.IGNORECASE) is not None)
  19. # Store a new session_id for a user that has logged in
  20. # The session token is stored in the user cookies during login, here
  21. # we store the hash value of that token.
  22. def new_session(user_id, session_token):
  23. with db:
  24. db.execute(
  25. """
  26. UPDATE user
  27. SET session = SHA512(:session)
  28. WHERE id = :user
  29. """,
  30. {
  31. 'user': user_id,
  32. 'session': session_token
  33. }
  34. )
  35. # Delete user session token on logout
  36. def delete_session (user_id):
  37. with db:
  38. db.execute (
  39. """
  40. UPDATE user
  41. SET session = NULL
  42. WHERE id = :user
  43. """,
  44. {
  45. 'user': user_id
  46. }
  47. )
  48. # Check user login credentials
  49. #
  50. # @return None if bad credentials, otherwise return the user
  51. def check_user_credentials (username, password):
  52. with db:
  53. cursor = db.execute (
  54. """
  55. SELECT *
  56. FROM user
  57. WHERE username = :username
  58. AND password = SHA512(:password || salt)
  59. AND isActive = 1
  60. """,
  61. {
  62. 'username': username,
  63. 'password': password
  64. }
  65. )
  66. return cursor.fetchone ()
  67. # Check if username exists
  68. def username_exists (username, case_sensitive = True):
  69. if not username:
  70. return None
  71. if case_sensitive:
  72. where = 'WHERE username = :username'
  73. else:
  74. where = 'WHERE LOWER(username) = LOWER(:username)'
  75. with db:
  76. cursor = db.execute(
  77. """
  78. SELECT *
  79. FROM user
  80. """ +
  81. where,
  82. {
  83. 'username': username
  84. }
  85. )
  86. return cursor.fetchone() is not None
  87. # Check if post with same link exists. This is used to check for duplicates.
  88. # Returns an empty list if the link wasn't posted before, otherwise returns the posts.
  89. def link_exists (link):
  90. if not link:
  91. return []
  92. with db:
  93. cursor = db.execute(
  94. """
  95. SELECT *
  96. FROM post
  97. WHERE LOWER(link) = LOWER(:link)
  98. ORDER BY created DESC
  99. """,
  100. {
  101. 'link': link
  102. }
  103. )
  104. return cursor.fetchall()
  105. # Create new user account
  106. def new_user (username, password):
  107. # Create a hash_id for the new post
  108. hash_id = random.alphanumeric_string (10)
  109. # Create a salt for user's password
  110. salt = random.ascii_string (16)
  111. # Add user to database
  112. with db:
  113. db.execute (
  114. """
  115. INSERT INTO user (hashId, isActive, password, registered, salt, username)
  116. VALUES (:hash_id, 1, SHA512(:password || :salt), DATE(), :salt, :username)
  117. """,
  118. {
  119. 'hash_id': hash_id,
  120. 'password': password,
  121. 'salt': salt,
  122. 'username': username
  123. }
  124. )
  125. # Check if session token exists
  126. def is_valid_session (token):
  127. return get_user_by_session_token (token) is not None
  128. # Return the number of unread replies
  129. def count_unread_messages (user_id):
  130. with db:
  131. cursor = db.execute (
  132. """
  133. SELECT COUNT(1) AS new_messages
  134. FROM comment
  135. WHERE parentUserId = :user AND userId != :user AND `read` = 0
  136. """,
  137. {
  138. 'user': user_id
  139. }
  140. )
  141. return cursor.fetchone ()['new_messages']
  142. # Retrieve a user
  143. def get_user_by_username (username):
  144. if not username:
  145. return None
  146. with db:
  147. cursor = db.execute(
  148. """
  149. SELECT *
  150. FROM user
  151. WHERE username = :username
  152. """,
  153. {
  154. 'username': username
  155. }
  156. )
  157. return cursor.fetchone()
  158. # Retrieve a user from a session cookie
  159. def get_user_by_session_token(session_token):
  160. with db:
  161. cursor = db.execute(
  162. """
  163. SELECT *
  164. FROM user
  165. WHERE session = SHA512(:session)
  166. """,
  167. {
  168. 'session': session_token
  169. }
  170. )
  171. return cursor.fetchone()
  172. # Get posts by date (for homepage)
  173. def get_posts (page = 0, session_user_id = None, sort = 'hot', topic = None):
  174. if sort == 'new':
  175. sort = 'ORDER BY P.created DESC'
  176. else:
  177. sort = 'ORDER BY P.dateCreated DESC, P.vote DESC, P.commentsCount DESC'
  178. if topic:
  179. topic_name = 'WHERE T.name = :topic'
  180. else:
  181. topic_name = ''
  182. with db:
  183. cursor = db.execute (
  184. """
  185. SELECT P.*,
  186. U.username,
  187. V.vote AS user_vote,
  188. GROUP_CONCAT(T.name, " ") AS topics
  189. FROM post AS P
  190. JOIN user AS U ON P.userId = U.id
  191. LEFT JOIN vote_post as V ON V.postId = P.id AND V.userId = :user
  192. LEFT JOIN topic as T ON T.post_id = P.id
  193. {topic}
  194. GROUP BY P.id
  195. {order}
  196. LIMIT :limit
  197. OFFSET :offset
  198. """.format (topic=topic_name, order=sort),
  199. {
  200. 'user': session_user_id,
  201. 'limit': settings['defaults']['items_per_page'],
  202. 'offset': page * settings['defaults']['items_per_page'],
  203. 'topic': topic
  204. }
  205. )
  206. return cursor.fetchall ()
  207. # Retrieve user's own posts
  208. def get_user_posts (user_id):
  209. with db:
  210. cursor = db.execute (
  211. """
  212. SELECT *
  213. FROM post
  214. WHERE userId = :user
  215. ORDER BY created DESC
  216. LIMIT 50
  217. """,
  218. {
  219. 'user': user_id
  220. }
  221. )
  222. return cursor.fetchall()
  223. # Retrieve user's own comments
  224. def get_user_comments (user_id):
  225. with db:
  226. cursor = db.execute (
  227. """
  228. SELECT C.*,
  229. P.title AS postTitle,
  230. P.hashId AS postHashId
  231. FROM comment AS C
  232. JOIN post AS P ON P.id = C.postId
  233. WHERE C.userId = :user
  234. ORDER BY C.created DESC
  235. LIMIT 50
  236. """,
  237. {
  238. 'user': user_id
  239. }
  240. )
  241. return cursor.fetchall()
  242. # Retrieve user's own replies to other people
  243. def get_user_replies (user_id):
  244. with db:
  245. cursor = db.execute(
  246. """
  247. SELECT C.*,
  248. P.title AS postTitle,
  249. P.hashId AS postHashId,
  250. U.username AS username
  251. FROM comment AS C
  252. JOIN post AS P ON P.id = C.postId
  253. JOIN user AS U ON U.id = C.userId
  254. WHERE C.parentUserId = :user AND C.userId != :user
  255. ORDER BY C.created DESC
  256. LIMIT 50
  257. """,
  258. {
  259. 'user': user_id
  260. }
  261. )
  262. return cursor.fetchall()
  263. # Update user information
  264. def update_user (user_id, about, email, email_notifications, preferred_feed):
  265. with db:
  266. # Update user info, but not email address
  267. db.execute(
  268. """
  269. UPDATE user
  270. SET about = :about,
  271. email_notifications = :notifications,
  272. preferred_feed = :preferred_feed
  273. WHERE id = :user
  274. """,
  275. {
  276. 'about': about,
  277. 'notifications': email_notifications,
  278. 'user': user_id,
  279. 'preferred_feed': preferred_feed
  280. }
  281. )
  282. # Update email address. Convert all addresses to LOWER() case. This
  283. # prevents two users from using the same address with different case.
  284. # IGNORE update if the email address is already specified. This is
  285. # necessary to avoid an "duplicate key" exception when updating value.
  286. db.execute (
  287. """
  288. UPDATE OR IGNORE user
  289. SET email = LOWER(:email)
  290. WHERE id = :user
  291. """,
  292. {
  293. 'email': email,
  294. 'user': user_id
  295. }
  296. )
  297. # Set user replies as read
  298. def set_replies_as_read (user_id):
  299. with db:
  300. db.execute(
  301. """
  302. UPDATE comment
  303. SET `read` = 1
  304. WHERE parentUserId = :user AND `read` = 0
  305. """,
  306. {
  307. 'user': user_id
  308. }
  309. )
  310. # Submit a new post/link
  311. def new_post (title, link, text, user_id):
  312. # Create a hash_id for the new post
  313. hash_id = random.alphanumeric_string (10)
  314. with db:
  315. db.execute(
  316. """
  317. INSERT INTO post (hashId, created, dateCreated, title,
  318. link, text, vote, commentsCount, userId)
  319. VALUES (:hash_id, DATETIME(), DATE(), :title, :link,
  320. :text, 0, 0, :user)
  321. """,
  322. {
  323. 'hash_id': hash_id,
  324. 'title': title,
  325. 'link': link,
  326. 'text': text,
  327. 'user': user_id
  328. }
  329. )
  330. return hash_id
  331. # Set topics post. Deletes existing ones.
  332. def replace_post_topics (post_id, topics = ''):
  333. if not topics:
  334. return
  335. # Normalize topics
  336. # 1. Split topics by space
  337. # 2. Remove empty strings
  338. # 3. Lower case topic name
  339. topics = [ topic.lower () for topic in topics.split (' ') if topic ]
  340. if len (topics) == 0:
  341. return
  342. # Remove extra topics if the list is too long
  343. topics = topics[:settings['defaults']['topics_per_post']]
  344. with db:
  345. # First we delete the existing topics
  346. db.execute (
  347. """
  348. DELETE
  349. FROM topic
  350. WHERE post_id = :post
  351. """,
  352. {
  353. 'post': post_id
  354. }
  355. )
  356. # Now insert the new topics.
  357. # IGNORE duplicates that trigger UNIQUE constraint.
  358. db.executemany (
  359. """
  360. INSERT OR IGNORE INTO topic (post_id, name)
  361. VALUES (?, ?)
  362. """,
  363. [ (post_id, topic) for topic in topics ]
  364. )
  365. # Retrieve a post
  366. def get_post (hash, session_user_id = None):
  367. with db:
  368. cursor = db.execute (
  369. """
  370. SELECT P.*,
  371. U.username,
  372. V.vote AS user_vote
  373. FROM post AS P
  374. JOIN user AS U ON P.userId = U.id
  375. LEFT JOIN vote_post as V ON V.postId = P.id AND V.userId = :user
  376. WHERE P.hashId = :post
  377. """,
  378. {
  379. 'user': session_user_id,
  380. 'post': hash
  381. }
  382. )
  383. return cursor.fetchone ()
  384. # Update a post
  385. def update_post (title, link, text, post_hash_id, user_id):
  386. with db:
  387. db.execute (
  388. """
  389. UPDATE post
  390. SET title = :title,
  391. link = :link,
  392. text = :text
  393. WHERE hashId = :hash_id
  394. AND userId = :user
  395. """,
  396. {
  397. 'title': title,
  398. 'link': link,
  399. 'text': text,
  400. 'hash_id': post_hash_id,
  401. 'user': user_id
  402. }
  403. )
  404. # Retrieve all comments for a specific post
  405. def get_post_comments (post_id, session_user_id = None):
  406. with db:
  407. cursor = db.execute (
  408. """
  409. SELECT C.*,
  410. U.username,
  411. V.vote AS user_vote
  412. FROM comment AS C
  413. JOIN user AS U ON C.userId = U.id
  414. LEFT JOIN vote_comment as V ON V.commentId = C.id AND V.userId = :user
  415. WHERE C.postId = :post
  416. ORDER BY C.vote DESC,
  417. C.created ASC
  418. """,
  419. {
  420. 'user': session_user_id,
  421. 'post': post_id
  422. }
  423. )
  424. return cursor.fetchall ()
  425. # Retrieve all topics for a specific post
  426. def get_post_topics (post_id):
  427. with db:
  428. cursor = db.execute (
  429. """
  430. SELECT T.name
  431. FROM topic AS T
  432. WHERE T.post_id = :post
  433. ORDER BY T.name ASC
  434. """,
  435. {
  436. 'post': post_id
  437. }
  438. )
  439. return cursor.fetchall ()
  440. # Submit a new comment to a post
  441. def new_comment (comment_text, post_hash_id, user_id, parent_user_id = None, parent_comment_id = None):
  442. # Create a hash_id for the new comment
  443. hash_id = random.alphanumeric_string (10)
  444. # Retrieve post
  445. post = get_post (post_hash_id)
  446. with db:
  447. db.execute (
  448. """
  449. INSERT INTO comment (hashId, created, dateCreated, `read`, text, vote,
  450. parentId, parentUserId, postId, userId)
  451. VALUES (:hash_id, DATETIME(), DATE(), 0, :text, 0, :parent_id,
  452. :parent_user_id, :post_id, :user)
  453. """,
  454. {
  455. 'hash_id': hash_id,
  456. 'text': comment_text,
  457. 'parent_id': parent_comment_id,
  458. 'parent_user_id': parent_user_id,
  459. 'post_id': post['id'],
  460. 'user': user_id
  461. }
  462. )
  463. # Increase comments count for post
  464. db.execute (
  465. """
  466. UPDATE post
  467. SET commentsCount = commentsCount + 1
  468. WHERE id = :post
  469. """,
  470. {
  471. 'post': post['id']
  472. }
  473. )
  474. return hash_id
  475. # Retrieve a single comment
  476. def get_comment (hash_id, session_user_id = None):
  477. with db:
  478. cursor = db.execute(
  479. """
  480. SELECT C.*,
  481. P.hashId AS postHashId,
  482. P.title AS postTitle,
  483. U.username,
  484. V.vote AS user_vote
  485. FROM comment AS C
  486. JOIN user AS U ON C.userId = U.id
  487. JOIN post AS P ON P.id = C.postId
  488. LEFT JOIN vote_comment as V ON V.commentId = C.id AND V.userId = :user
  489. WHERE C.hashId = :comment
  490. """,
  491. {
  492. 'user': session_user_id,
  493. 'comment': hash_id
  494. }
  495. )
  496. return cursor.fetchone()
  497. # Retrieve last N newest comments
  498. def get_latest_comments ():
  499. with db:
  500. cursor = db.execute (
  501. """
  502. SELECT C.*,
  503. P.hashId AS postHashId,
  504. P.title AS postTitle,
  505. U.username
  506. FROM comment AS C
  507. JOIN user AS U ON C.userId = U.id
  508. JOIN post AS P ON P.id = C.postId
  509. ORDER BY C.id DESC
  510. LIMIT 50
  511. """,
  512. {
  513. }
  514. )
  515. return cursor.fetchall ()
  516. # Update a comment
  517. def update_comment (text, comment_hash_id, user_id):
  518. with db:
  519. db.execute (
  520. """
  521. UPDATE comment
  522. SET text = :text
  523. WHERE hashId = :comment AND userId = :user
  524. """,
  525. {
  526. 'text': text,
  527. 'comment': comment_hash_id,
  528. 'user': user_id
  529. }
  530. )
  531. # Add or update vote to a post
  532. def vote_post (post_id, user_id, vote):
  533. with db:
  534. # Create a new vote for this post, if one doesn't already exist
  535. db.execute(
  536. """
  537. INSERT OR IGNORE INTO vote_post (vote, datetime, postId, userId)
  538. VALUES (0, DATETIME(), :post, :user)
  539. """,
  540. {
  541. 'post': post_id,
  542. 'user': user_id
  543. }
  544. )
  545. # Update user vote (+1 or -1)
  546. db.execute(
  547. """
  548. UPDATE vote_post
  549. SET vote = vote + :vote
  550. WHERE postId = :post AND userId = :user
  551. """,
  552. {
  553. 'vote': vote,
  554. 'post': post_id,
  555. 'user': user_id
  556. }
  557. )
  558. # Update post's total
  559. db.execute (
  560. """
  561. UPDATE post
  562. SET vote = vote + :vote
  563. WHERE id = :post
  564. """,
  565. {
  566. 'vote': vote,
  567. 'post': post_id
  568. }
  569. )
  570. # Add or update vote to a comment
  571. def vote_comment (comment_id, user_id, vote):
  572. with db:
  573. # Create a new vote for this post, if one doesn't already exist
  574. db.execute (
  575. """
  576. INSERT INTO vote_comment (vote, datetime, commentId, userId)
  577. VALUES (0, DATETIME(), :comment, :user)
  578. """,
  579. {
  580. 'comment': comment_id,
  581. 'user': user_id
  582. }
  583. )
  584. # Update user vote (+1 or -1)
  585. db.execute (
  586. """
  587. UPDATE vote_comment
  588. SET vote = vote + :vote
  589. WHERE commentId = :comment AND userId = :user
  590. """,
  591. {
  592. 'vote': vote,
  593. 'comment': comment_id,
  594. 'user': user_id
  595. }
  596. )
  597. # Update comment's total
  598. db.execute (
  599. """
  600. UPDATE comment
  601. SET vote = vote + :vote
  602. WHERE id = :comment
  603. """,
  604. {
  605. 'vote': vote,
  606. 'comment': comment_id
  607. }
  608. )
  609. # Search posts
  610. def search (query, sort='newest', page=0):
  611. if not query:
  612. return []
  613. # Remove multiple white spaces and replace with '|' (for query REGEXP)
  614. query = re.sub (' +', '|', query.strip ())
  615. if len (query) == 0:
  616. return []
  617. if sort == 'newest':
  618. sort = 'P.created DESC'
  619. if sort == 'points':
  620. sort = 'P.vote DESC'
  621. with db:
  622. cursor = db.execute (
  623. """
  624. SELECT P.*,
  625. U.username
  626. FROM post AS P
  627. JOIN user AS U ON P.userId = U.id
  628. WHERE P.title REGEXP :query
  629. ORDER BY {sort}
  630. LIMIT :limit
  631. OFFSET :offset
  632. """.format (sort=sort),
  633. {
  634. 'query': query,
  635. 'sort': sort,
  636. 'limit': settings['defaults']['search_results_per_page'],
  637. 'offset': page * settings['defaults']['search_results_per_page']
  638. }
  639. )
  640. return cursor.fetchall ()
  641. # Set reset token for user email
  642. def set_password_reset_token (user_id = None, token = None):
  643. if not user_id or not token:
  644. return
  645. with db:
  646. db.execute (
  647. """
  648. UPDATE user
  649. SET passwordResetToken = SHA512(:token),
  650. passwordResetTokenExpire = DATETIME('now', '+1 HOUR')
  651. WHERE id = :user
  652. """,
  653. {
  654. 'user': user_id,
  655. 'token': token
  656. }
  657. )
  658. # Delete the password reset token for a user
  659. def delete_password_reset_token (user_id = None):
  660. with db:
  661. db.execute (
  662. """
  663. UPDATE user
  664. SET passwordResetToken = NULL,
  665. passwordResetTokenExpire = NULL
  666. WHERE id = :user
  667. """,
  668. {
  669. 'user': user_id
  670. }
  671. )
  672. # Check if a reset token has expired.
  673. def is_password_reset_token_valid (user_id = None):
  674. with db:
  675. cursor = db.execute(
  676. """
  677. SELECT COUNT(1) AS valid
  678. FROM user
  679. WHERE id = :user
  680. AND passwordResetToken IS NOT NULL
  681. AND passwordResetTokenExpire IS NOT NULL
  682. AND passwordResetTokenExpire > DATETIME('now')
  683. """,
  684. {
  685. 'user': user_id
  686. }
  687. )
  688. return cursor.fetchone()['valid'] == 1
  689. # Reset user password
  690. def reset_password (username = None, email = None, new_password = None, secret_token = None):
  691. if not new_password:
  692. return
  693. with db:
  694. db.execute (
  695. """
  696. UPDATE user
  697. SET password = SHA512(:password || salt),
  698. passwordResetToken = NULL,
  699. passwordResetTokenExpire = NULL
  700. WHERE username = :user
  701. AND email = :email
  702. AND passwordResetToken = SHA512(:token)
  703. AND passwordResetTokenExpire > DATE()
  704. """,
  705. {
  706. 'password': new_password,
  707. 'user': username,
  708. 'email': email,
  709. 'token': secret_token
  710. }
  711. )