# Create notifications
for target in notification_targets:
- query_db("insert into comment_notifications (commentid, targetuserid) values (?, ?)", [commentid, target])
+ query_db("insert into notifications (objectid, objecttype, targetuserid, created) values (?, ?, ?, ?)", [commentid, ObjectType.COMMENT, target, timestamp])
get_db().commit()
if not "userid" in session:
return redirect("/login")
- # TODO: Update activity page to handle other comment types
# Get comment notifications
comments = query_db(
"""\
select c.content, c.commentid, c.replytoid, cu.username as comment_username, rc.content as replyto_content, c.threadid, t.threadtype
- from comment_notifications as cn
- inner join comments as c on cn.commentid == c.commentid
+ from notifications as n
+ inner join comments as c on n.objectid == c.commentid
inner join comment_threads as t on c.threadid = t.threadid
left join comments as rc on c.replytoid == rc.commentid
inner join users as cu on cu.userid == c.userid
- where cn.targetuserid = ?
+ where (n.targetuserid = ?) and (n.objecttype = ?)
order by c.created desc
""",
- [session["userid"]])
+ [session["userid"], ObjectType.COMMENT])
comments = [dict(c) for c in comments]
for comment in comments:
comment["content_userid"] = playlist["userid"]
comment["content_username"] = playlist["username"]
-
timestamp = datetime.now(timezone.utc).isoformat()
query_db("update users set activitytime = ? where userid = ?", [timestamp, session["userid"]])
get_db().commit()
user_data = query_db("select activitytime from users where userid = ?", [session["userid"]], one=True)
comment_data = query_db(
"""\
- select c.created from comment_notifications as cn
- inner join comments as c on cn.commentid = c.commentid
- where cn.targetuserid = ?
- order by c.created desc
+ select created from notifications
+ where targetuserid = ?
+ order by created desc
limit 1""",
[session["userid"]],
one=True)
comment_cur.close()
cur.close()
- # Copy song comment notifications to new comment notifications table
- cur = db.execute(
- """\
- insert into comment_notifications
- select * from song_comment_notifications
+ # Copy song comment notifications to new notifications table
+ cur = db.execute("""\
+ select * from song_comment_notifications as scn
+ inner join song_comments as sc on
+ scn.commentid = sc.commentid
""")
+ for row in cur:
+ db.execute(
+ """\
+ insert into notifications (notificationid, objectid, objecttype, targetuserid, created)
+ values (?, ?, ?, ?, ?)
+ """,
+ [row["notificationid"], row["commentid"], ObjectType.COMMENT, row["targetuserid"], row["created"]])
db.execute("PRAGMA user_version = 4").close()
import secrets
print(secrets.token_hex())
+class ObjectType(enum.IntEnum):
+ COMMENT = 0
+
class ThreadType(enum.IntEnum):
SONG = 0
PROFILE = 1
--- /dev/null
+DROP TRIGGER trg_delete_song_comments;
+DROP TRIGGER trg_delete_profile_comments;
+DROP TRIGGER trg_delete_playlist_comments;
+ALTER TABLE songs DROP COLUMN threadid;
+ALTER TABLE users DROP COLUMN threadid;
+ALTER TABLE playlists DROP COLUMN threadid;
+DROP TABLE notifications;
+DROP TABLE comments;
+DROP TABLE comment_threads;
+PRAGMA user_version = 3;
--- Create new comment tables
+-- Add comment thread to songs table
+ALTER TABLE songs ADD COLUMN threadid INTEGER;
+
+-- Add profile comment thread to users table
+ALTER TABLE users ADD COLUMN threadid INTEGER;
+
+-- Add playlist comment thread to playlists table
+ALTER TABLE playlists ADD COLUMN threadid INTEGER;
+
CREATE TABLE comment_threads (
threadid INTEGER PRIMARY KEY,
threadtype INTEGER NOT NULL,
FOREIGN KEY(userid) REFERENCES users(userid) ON DELETE CASCADE
);
+-- Delete comment thread when song deleted
+CREATE TRIGGER trg_delete_song_comments
+BEFORE DELETE ON songs FOR EACH ROW
+BEGIN
+ DELETE FROM comment_threads WHERE threadid = OLD.threadid;
+END;
+
+-- Delete comment thread when profile deleted
+CREATE TRIGGER trg_delete_profile_comments
+BEFORE DELETE ON users FOR EACH ROW
+BEGIN
+ DELETE FROM comment_threads WHERE threadid = OLD.threadid;
+END;
+
+-- Delete comment thread when playlist deleted
+CREATE TRIGGER trg_delete_playlist_comments
+BEFORE DELETE ON playlists FOR EACH ROW
+BEGIN
+ DELETE FROM comment_threads WHERE threadid = OLD.threadid;
+END;
+
CREATE TABLE comments (
commentid INTEGER PRIMARY KEY,
threadid INTEGER NOT NULL,
CREATE INDEX idx_comments_replyto ON comments(replytoid);
CREATE INDEX idx_comments_time ON comments(created);
-CREATE TABLE comment_notifications (
+CREATE TABLE notifications (
notificationid INTEGER PRIMARY KEY,
- commentid INTEGER NOT NULL,
+ objectid INTEGER NOT NULL,
+ objecttype INTEGER NOT NULL,
targetuserid INTEGER NOT NULL,
- FOREIGN KEY(commentid) REFERENCES comments(commentid) ON DELETE CASCADE,
+ created TEXT NOT NULL,
FOREIGN KEY(targetuserid) REFERENCES users(userid) ON DELETE CASCADE
);
-CREATE INDEX idx_comment_notifications_by_target ON comment_notifications(targetuserid);
-
--- Add comment thread to songs table
-ALTER TABLE songs ADD COLUMN threadid INTEGER;
+CREATE INDEX idx_notifications_by_target ON notifications(targetuserid);
+CREATE INDEX idx_notifications_by_object ON notifications(objectid);
--- Add profile comment thread to users table
-ALTER TABLE users ADD COLUMN threadid INTEGER;
-
--- Add playlist comment thread to playlists table
-ALTER TABLE playlists ADD COLUMN threadid INTEGER;
+-- Delete comment notifications when comment deleted
+CREATE TRIGGER trg_delete_notifications
+BEFORE DELETE ON comments FOR EACH ROW
+BEGIN
+ DELETE FROM notifications WHERE objectid = OLD.commentid AND objecttype = 0;
+END;