home » zplus/freepost.git
ID: ed49217793a3cc9059fa234d698139da1bd6e186
728 lines — 18K — View raw


  1
  2
  3
  4
  5
  6
  7
  8
  9
 10
 11
 12
 13
 14
 15
 16
 17
 18
 19
 20
 21
 22
 23
 24
 25
 26
 27
 28
 29
 30
 31
 32
 33
 34
 35
 36
 37
 38
 39
 40
 41
 42
 43
 44
 45
 46
 47
 48
 49
 50
 51
 52
 53
 54
 55
 56
 57
 58
 59
 60
 61
 62
 63
 64
 65
 66
 67
 68
 69
 70
 71
 72
 73
 74
 75
 76
 77
 78
 79
 80
 81
 82
 83
 84
 85
 86
 87
 88
 89
 90
 91
 92
 93
 94
 95
 96
 97
 98
 99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
141
142
143
144
145
146
147
148
149
150
151
152
153
154
155
156
157
158
159
160
161
162
163
164
165
166
167
168
169
170
171
172
173
174
175
176
177
178
179
180
181
182
183
184
185
186
187
188
189
190
191
192
193
194
195
196
197
198
199
200
201
202
203
204
205
206
207
208
209
210
211
212
213
214
215
216
217
218
219
220
221
222
223
224
225
226
227
228
229
230
231
232
233
234
235
236
237
238
239
240
241
242
243
244
245
246
247
248
249
250
251
252
253
254
255
256
257
258
259
260
261
262
263
264
265
266
267
268
269
270
271
272
273
274
275
276
277
278
279
280
281
282
283
284
285
286
287
288
289
290
291
292
293
294
295
296
297
298
299
300
301
302
303
304
305
306
307
308
309
310
311
312
313
314
315
316
317
318
319
320
321
322
323
324
325
326
327
328
329
330
331
332
333
334
335
336
337
338
339
340
341
342
343
344
345
346
347
348
349
350
351
352
353
354
355
356
357
358
359
360
361
362
363
364
365
366
367
368
369
370
371
372
373
374
375
376
377
378
379
380
381
382
383
384
385
386
387
388
389
390
391
392
393
394
395
396
397
398
399
400
401
402
403
404
405
406
407
408
409
410
411
412
413
414
415
416
417
418
419
420
421
422
423
424
425
426
427
428
429
430
431
432
433
434
435
436
437
438
439
440
441
442
443
444
445
446
447
448
449
450
451
452
453
454
455
456
457
458
459
460
461
462
463
464
465
466
467
468
469
470
471
472
473
474
475
476
477
478
479
480
481
482
483
484
485
486
487
488
489
490
491
492
493
494
495
496
497
498
499
500
501
502
503
504
505
506
507
508
509
510
511
512
513
514
515
516
517
518
519
520
521
522
523
524
525
526
527
528
529
530
531
532
533
534
535
536
537
538
539
540
541
542
543
544
545
546
547
548
549
550
551
552
553
554
555
556
557
558
559
560
561
562
563
564
565
566
567
568
569
570
571
572
573
574
575
576
577
578
579
580
581
582
583
584
585
586
587
588
589
590
591
592
593
594
595
596
597
598
599
600
601
602
603
604
605
606
607
608
609
610
611
612
613
614
615
616
617
618
619
620
621
622
623
624
625
626
627
628
629
630
631
632
633
634
635
636
637
638
639
640
641
642
643
644
645
646
647
648
649
650
651
652
653
654
655
656
657
658
659
660
661
662
663
664
665
666
667
668
669
670
671
672
673
674
675
676
677
678
679
680
681
682
683
684
685
686
687
688
689
690
691
692
693
694
695
696
697
698
699
700
701
702
703
704
705
706
707
708
709
import MySQLdb
import re
from freepost import random, settings

db = MySQLdb.connect (
    host       = settings['mysql']['host'],
    port       = settings['mysql']['port'],
    db         = settings['mysql']['schema'],
    user       = settings['mysql']['username'],
    passwd     = settings['mysql']['password'],
    autocommit = True)

# Since the "db" object is reused for the entire life of website,
# this ping should avoid MySQL timing out if no requests are sent in a while.
db.ping (True)

# Store a new session_id for a user that has logged in
# The session token is stored in the user cookies during login, here
# we store the hash value of that token.
def new_session (user_id, session_token):
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        UPDATE user
        SET session = SHA2(%(session)s, 512)
        WHERE id = %(user)s
        """,
        {
            'user': user_id,
            'session': session_token
        }
    )

# Delete user session token on logout
def delete_session (user_id):
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        UPDATE user
        SET session = NULL
        WHERE id = %(user)s
        """,
        {
            'user': user_id
        }
    )

# Check user login credentials
# 
# @return None if bad credentials, otherwise return the user
def check_user_credentials (username, password):
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        SELECT *
        FROM user
        WHERE
            username = %(username)s AND
            password = SHA2(CONCAT(%(password)s, salt), 512) AND
            isActive = 1
        """,
        {
            'username': username,
            'password': password
        }
    )
    
    return cursor.fetchone ()

# Check if username exists
def username_exists (username):
    return get_user_by_username (username) is not None

# Create new user account
def new_user (username, password):
    # Create a hash_id for the new post
    hash_id = random.alphanumeric_string (10)
    
    # Create a salt for user's password
    salt = random.ascii_string (16)
    
    # Add user to database
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        INSERT INTO user (hashId, isActive, password, registered, salt, username)
        VALUES (%(hash_id)s, 1, SHA2(CONCAT(%(password)s, %(salt)s), 512), NOW(), %(salt)s, %(username)s)
        """,
        {
            'hash_id': hash_id,
            'password': password,
            'salt': salt,
            'username': username
        }
    )

# Check if session token exists
def is_valid_session (token):
    return get_user_by_session_token (token) is not None

# Return the number of unread replies
def count_unread_messages (user_id):
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        SELECT COUNT(1) as new_messages
        FROM comment
        WHERE parentUserId = %(user)s AND userId != %(user)s AND `read` = 0
        """,
        {
            'user': user_id
        }
    )
        
    return cursor.fetchone ()['new_messages']

# Retrieve a user
def get_user_by_username (username):
    if not username:
        return None
    
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        SELECT *
        FROM user
        WHERE username = %(username)s
        """,
        {
            'username': username
        }
    )
        
    return cursor.fetchone ()

# Retrieve a user from a session cookie
def get_user_by_session_token (session_token):
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        SELECT *
        FROM user
        WHERE session = SHA2(%(session)s, 512)
        """,
        {
            'session': session_token
        }
    )
        
    return cursor.fetchone ()

# Get posts by date (for homepage)
def get_posts (page = 0, session_user_id = None, sort = 'hot', topic = None):
    if sort == 'new':
        sort = 'ORDER BY P.created DESC'
    else:
        sort = 'ORDER BY P.dateCreated DESC, P.vote DESC, P.commentsCount DESC'
    
    if topic:
        topic_name = 'WHERE T.name = %(topic)s'
    else:
        topic_name = ''
    
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        SELECT
            P.*,
            U.username,
            V.vote AS user_vote,
            GROUP_CONCAT(DISTINCT T.name ORDER BY T.name SEPARATOR " ") AS topics
        FROM post AS P
        JOIN user AS U ON P.userId = U.id
        LEFT JOIN vote_post as V ON V.postId = P.id AND V.userId = %(user)s
        LEFT JOIN topic as T ON T.post_id = P.id
        {topic}
        GROUP BY P.id
        {order}
        LIMIT %(limit)s
        OFFSET %(offset)s
        """.format (topic=topic_name, order=sort),
        {
            'user': session_user_id,
            'limit': settings['defaults']['items_per_page'],
            'offset': page * settings['defaults']['items_per_page'],
            'topic': topic
        }
    )
    
    return cursor.fetchall ()

# Retrieve user's own posts
def get_user_posts (user_id):
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        SELECT *
        FROM post
        WHERE userId = %(user)s
        ORDER BY created DESC
        LIMIT 50
        """,
        {
            'user': user_id
        }
    )
    
    return cursor.fetchall ()

# Retrieve user's own comments
def get_user_comments (user_id):
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        SELECT
            C.*,
            P.title AS postTitle,
            P.hashId AS postHashId
        FROM comment AS C
        JOIN post AS P ON P.id = C.postId
        WHERE C.userId = %(user)s
        ORDER BY C.created DESC
        LIMIT 50
        """,
        {
            'user': user_id
        }
    )
    
    return cursor.fetchall ()

# Retrieve user's own replies to other people
def get_user_replies (user_id):
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        SELECT
            C.*,
            P.title AS postTitle,
            P.hashId AS postHashId,
            U.username AS username
        FROM comment AS C
        JOIN post AS P ON P.id = C.postId
        JOIN user AS U ON U.id = C.userId
        WHERE C.parentUserId = %(user)s AND C.userId != %(user)s
        ORDER BY C.created DESC
        LIMIT 50
        """,
        {
            'user': user_id
        }
    )
    
    return cursor.fetchall ()

# Update user information
def update_user (user_id, about, email, email_notifications):
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    # Update user info, but not email address
    cursor.execute (
        """
        UPDATE user
        SET about = %(about)s,
            email_notifications = %(notifications)s
        WHERE id = %(user)s
        """,
        {
            'about': about,
            'notifications': email_notifications,
            'user': user_id
        }
    )
        
    # Update email address
    # IGNORE update if the email address is already specified. This is
    # necessary to avoid an "duplicate key" exception when updating value.
    cursor.execute (
        """
        UPDATE IGNORE user
        SET email = %(email)s
        WHERE id = %(user)s
        """,
        {
            'email': email,
            'user': user_id
        }
    )

# Set user replies as read
def set_replies_as_read (user_id):
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        UPDATE comment
        SET `read` = 1
        WHERE parentUserId = %(user)s AND `read` = 0
        """,
        {
            'user': user_id
        }
    )

# Submit a new post/link
def new_post (title, link, text, user_id):
    # Create a hash_id for the new post
    hash_id = random.alphanumeric_string (10)
    
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        INSERT INTO post (hashId, created, dateCreated, title,
                          link, text, vote, commentsCount, userId)
        VALUES (%(hash_id)s, NOW(), CURDATE(), %(title)s, %(link)s,
                %(text)s, 0, 0, %(user)s)
        """,
        {
            'hash_id': hash_id,
            'title': title,
            'link': link,
            'text': text,
            'user': user_id
        }
    )
    
    return hash_id

# Set topics post. Deletes existing ones.
def replace_post_topics (post_id, topics = ''):
    if not topics:
        return
    
    # Normalize topics
    # 1. Split topics by space
    # 2. Remove empty strings
    # 3. Lower case topic name
    topics = [ topic.lower () for topic in topics.split (' ') if topic ]
    
    if len (topics) == 0:
        return
    
    # Remove extra topics if the list is too long
    topics = topics[:settings['defaults']['topics_per_post']]
    
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    # First we delete the existing topics
    cursor.execute (
        """
        DELETE FROM topic WHERE post_id = %(post)s
        """,
        {
            'post': post_id
        }
    )
    
    # Now insert the new topics
    cursor.executemany (
        """
        INSERT INTO topic (post_id, name)
        VALUES (%s, %s)
        """,
        [ (post_id, topic) for topic in topics ]
    )

# Retrieve a post
def get_post (hash, session_user_id = None):
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        SELECT P.*, U.username, V.vote AS user_vote
        FROM post AS P
        JOIN user AS U ON P.userId = U.id
        LEFT JOIN vote_post as V ON V.postId = P.id AND V.userId = %(user)s
        WHERE P.hashId = %(post)s
        """,
        {
            'user': session_user_id,
            'post': hash
        }
    )
    
    return cursor.fetchone ()

# Update a post
def update_post (title, link, text, post_hash_id, user_id):
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        UPDATE post
        SET title = %(title)s,
            link  = %(link)s,
            text  = %(text)s
        WHERE hashId = %(hash_id)s AND userId = %(user)s
        """,
        {
            'title': title,
            'link': link,
            'text': text,
            'hash_id': post_hash_id,
            'user': user_id
        }
    )

# Retrieve all comments for a specific post
def get_post_comments (post_id, session_user_id = None):
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        SELECT C.*, U.username, V.vote AS user_vote
        FROM comment AS C
        JOIN user AS U ON C.userId = U.id
        LEFT JOIN vote_comment as V ON V.commentId = C.id AND V.userId = %(user)s
        WHERE C.postId = %(post)s
        ORDER BY C.vote DESC, C.created ASC
        """,
        {
            'user': session_user_id,
            'post': post_id
        }
    )
    
    return cursor.fetchall ()

# Submit a new comment to a post
def new_comment (comment_text, post_hash_id, user_id, parent_comment_id = None):
    # Create a hash_id for the new comment
    hash_id = random.alphanumeric_string (10)
    
    # Retrieve post
    post = get_post (post_hash_id)
    
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        INSERT INTO comment (hashId, created, dateCreated, `read`, `text`, `vote`,
                             parentId, parentUserId, postId, userId)
        VALUES (%(hash_id)s, NOW(), CURDATE(), 0, %(text)s, 0, %(parent_id)s,
                %(parent_user_id)s, %(post_id)s, %(user)s)
        """,
        {
            'hash_id': hash_id,
            'text': comment_text,
            'parent_id': parent_comment_id,
            'parent_user_id': post['userId'],
            'post_id': post['id'],
            'user': user_id
        }
    )
    
    # Increase comments count for post
    cursor.execute (
        """
        UPDATE post
        SET commentsCount = commentsCount + 1
        WHERE id = %(post)s
        """,
        {
            'post': post['id']
        }
    )
    
    return hash_id

# Retrieve a single comment
def get_comment (hash_id, session_user_id = None):
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        SELECT
            C.*,
            P.hashId AS postHashId,
            P.title AS postTitle,
            U.username,
            V.vote AS user_vote
        FROM comment AS C
        JOIN user AS U ON C.userId = U.id
        JOIN post AS P ON P.id = C.postId
        LEFT JOIN vote_comment as V ON V.commentId = C.id AND V.userId = %(user)s
        WHERE C.hashId = %(comment)s
        """,
        {
            'user': session_user_id,
            'comment': hash_id
        }
    )
    
    return cursor.fetchone ()

# Update a comment
def update_comment (text, comment_hash_id, user_id):
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        UPDATE comment
        SET text = %(text)s
        WHERE hashId = %(comment)s AND userId = %(user)s
        """,
        {
            'text': text,
            'comment': comment_hash_id,
            'user': user_id
        }
    )

# Add or update vote to a post
def vote_post (post_id, user_id, vote):
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    # Insert or update the user vote
    cursor.execute (
        """
        INSERT INTO vote_post (vote, datetime, postId, userId)
        VALUES (%(vote)s, NOW(), %(post)s, %(user)s)
        ON DUPLICATE KEY UPDATE
            vote = vote + %(vote)s,
            datetime = NOW()
        """,
        {
            'vote': vote,
            'post': post_id,
            'user': user_id
        }
    )
    
    # Update vote counter for post
    cursor.execute (
        """
        UPDATE post
        SET vote = vote + %(vote)s
        WHERE id = %(post)s
        """,
        {
            'vote': vote,
            'post': post_id
        }
    )

# Add or update vote to a comment
def vote_comment (comment_id, user_id, vote):
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    # Insert or update the user vote
    cursor.execute (
        """
        INSERT INTO vote_comment (vote, datetime, commentId, userId)
        VALUES (%(vote)s, NOW(), %(comment)s, %(user)s)
        ON DUPLICATE KEY UPDATE
            vote = vote + %(vote)s,
            datetime = NOW()
        """,
        {
            'vote': vote,
            'comment': comment_id,
            'user': user_id
        }
    )
    
    # Update vote counter for comment
    cursor.execute (
        """
        UPDATE comment
        SET vote = vote + %(vote)s
        WHERE id = %(comment)s
        """,
        {
            'vote': vote,
            'comment': comment_id
        }
    )

# Search posts
def search (query, sort='newest', page=0):
    if not query:
        return []
    
    # Remove multiple white spaces and replace with '|' (for query REGEXP)
    query = re.sub (' +', '|', query.strip ())
    
    if len (query) == 0:
        return []
    
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    if sort == 'newest':
        sort = 'P.created DESC'
    if sort == 'points':
        sort = 'P.vote DESC'
    
    cursor.execute (
        """
        SELECT P.*, U.username
        FROM post AS P
        JOIN user AS U ON P.userId = U.id
        WHERE P.title REGEXP %(query)s
        ORDER BY {sort}
        LIMIT %(limit)s
        OFFSET %(offset)s
        """.format (sort=sort),
        {
            'query': query,
            'sort': sort,
            'limit': settings['defaults']['search_results_per_page'],
            'offset': page * settings['defaults']['search_results_per_page']
        }
    )
    
    return cursor.fetchall ()

# Set reset token for user email
def set_password_reset_token (user_id = None, token = None):
    if not user_id or not token:
        return
    
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        UPDATE user
        SET passwordResetToken = SHA2(%(token)s, 512),
            passwordResetTokenExpire = NOW() + INTERVAL 1 HOUR
        WHERE id = %(user)s
        """,
        {
            'user': user_id,
            'token': token
        }
    )

# Delete the password reset token for a user
def delete_password_reset_token (user_id = None):
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        UPDATE user
        SET passwordResetToken = NULL,
            passwordResetTokenExpire = NULL
        WHERE id = %(user)s
        """,
        {
            'user': user_id
        }
    )

# Check if a reset token has expired.
def is_password_reset_token_valid (user_id = None):
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        SELECT COUNT(1) AS valid
        FROM user
        WHERE id = %(user)s AND
              passwordResetToken IS NOT NULL AND
              passwordResetTokenExpire IS NOT NULL AND
              passwordResetTokenExpire > NOW()
        """,
        {
            'user': user_id
        }
    )
    
    return cursor.fetchone ()['valid'] == 1

# Reset user password
def reset_password (username = None, email = None, new_password = None, secret_token = None):
    if not new_password:
        return
    
    cursor = db.cursor (MySQLdb.cursors.DictCursor)
    
    cursor.execute (
        """
        UPDATE user
        SET password = SHA2(CONCAT(%(password)s, `salt`), 512),
            passwordResetToken = NULL,
            passwordResetTokenExpire = NULL
        WHERE username = %(user)s AND
              email = %(email)s AND
              passwordResetToken = SHA2(%(token)s, 512) AND
              passwordResetTokenExpire > NOW()
        """,
        {
            'password': new_password,
            'user': username,
            'email': email,
            'token': secret_token
        }
    )