From 906571324ae2bf3cdc23f9ae970c1854142eb80d Mon Sep 17 00:00:00 2001 From: SatsAllDay <128755788+SatsAllDay@users.noreply.github.com> Date: Wed, 30 Aug 2023 21:38:31 -0400 Subject: [PATCH] De-dupe item-driven notifications (#457) * De-dupe item-driven notifications Update how we query for item-driven notifications to de-dupe them for: 1. mentions 2. replies 3. thread subscriptions 4. user subscriptions users should recieve only 1 notification for any given item created by another user, following the above priority order this is accomplished by querying for replies to current user, replies on subscribed threads, items from subscribed users, and mentions (if enabled for the current user), sorting those results by item id and priority order within item id based on notification type, then selecting the highest priority notification from each item id these results are then union all'ed with all other notification types, unchanged. * remove extra union hashing --------- Co-authored-by: keyan --- api/resolvers/notifications.js | 81 ++++++++++++++++++++++------------ 1 file changed, 52 insertions(+), 29 deletions(-) diff --git a/api/resolvers/notifications.js b/api/resolvers/notifications.js index 55f772f5..195177ea 100644 --- a/api/resolvers/notifications.js +++ b/api/resolvers/notifications.js @@ -71,32 +71,40 @@ export default { const queries = [] - queries.push( - `(SELECT DISTINCT "Item".id::TEXT, "Item".created_at AS "sortTime", NULL::BIGINT as "earnedSats", - 'Reply' AS type - FROM "Item" - JOIN "Item" p ON ${meFull.noteAllDescendants ? '"Item".path <@ p.path' : '"Item"."parentId" = p.id'} - WHERE p."userId" = $1 AND "Item"."userId" <> $1 AND "Item".created_at <= $2 - ${await filterClause(me, models)} - ORDER BY "sortTime" DESC - LIMIT ${LIMIT}+$3) - UNION DISTINCT - (SELECT DISTINCT "Item".id::TEXT, "Item".created_at AS "sortTime", NULL::BIGINT as "earnedSats", - 'Reply' AS type - FROM "ThreadSubscription" - JOIN "Item" p ON "ThreadSubscription"."itemId" = p.id - JOIN "Item" ON ${meFull.noteAllDescendants ? '"Item".path <@ p.path' : '"Item"."parentId" = p.id'} - WHERE - "ThreadSubscription"."userId" = $1 - AND "Item"."userId" <> $1 AND "Item".created_at <= $2 - ${await filterClause(me, models)} - ORDER BY "sortTime" DESC - LIMIT ${LIMIT}+$3)` + const itemDrivenQueries = [] + // Replies + itemDrivenQueries.push( + `SELECT DISTINCT "Item".id::TEXT, "Item".created_at AS "sortTime", NULL::BIGINT as "earnedSats", + 'Reply' AS type + FROM "Item" + JOIN "Item" p ON ${meFull.noteAllDescendants ? '"Item".path <@ p.path' : '"Item"."parentId" = p.id'} + WHERE p."userId" = $1 AND "Item"."userId" <> $1 AND "Item".created_at <= $2 + ${await filterClause(me, models)} + ORDER BY "sortTime" DESC + LIMIT ${LIMIT}+$3` ) - queries.push( - `(SELECT DISTINCT "Item".id::TEXT, "Item".created_at AS "sortTime", NULL::BIGINT as "earnedSats", + // Thread subscriptions + itemDrivenQueries.push( + `SELECT DISTINCT "Item".id::TEXT, "Item".created_at AS "sortTime", NULL::BIGINT as "earnedSats", + 'Reply' AS type + FROM "ThreadSubscription" + JOIN "Item" p ON "ThreadSubscription"."itemId" = p.id + JOIN "Item" ON ${meFull.noteAllDescendants ? '"Item".path <@ p.path' : '"Item"."parentId" = p.id'} + WHERE + "ThreadSubscription"."userId" = $1 + AND "Item"."userId" <> $1 AND "Item".created_at <= $2 + -- Only show items that have been created since subscribing to the thread + AND "Item".created_at >= "ThreadSubscription".created_at + ${await filterClause(me, models)} + ORDER BY "sortTime" DESC + LIMIT ${LIMIT}+$3` + ) + + // User subscriptions + itemDrivenQueries.push( + `SELECT DISTINCT "Item".id::TEXT, "Item".created_at AS "sortTime", NULL::BIGINT as "earnedSats", 'FollowActivity' AS type FROM "Item" JOIN "UserSubscription" ON "Item"."userId" = "UserSubscription"."followeeId" @@ -106,25 +114,40 @@ export default { AND "Item".created_at >= "UserSubscription".created_at ${await filterClause(me, models)} ORDER BY "sortTime" DESC - LIMIT ${LIMIT}+$3)` + LIMIT ${LIMIT}+$3` ) + // mentions if (meFull.noteMentions) { - queries.push( - `(SELECT "Item".id::TEXT, "Mention".created_at AS "sortTime", NULL as "earnedSats", + itemDrivenQueries.push( + `SELECT "Item".id::TEXT, "Mention".created_at AS "sortTime", NULL as "earnedSats", 'Mention' AS type FROM "Mention" JOIN "Item" ON "Mention"."itemId" = "Item".id - LEFT JOIN "Item" p ON "Item"."parentId" = p.id WHERE "Mention"."userId" = $1 AND "Mention".created_at <= $2 AND "Item"."userId" <> $1 - AND (p."userId" IS NULL OR p."userId" <> $1) ${await filterClause(me, models)} ORDER BY "sortTime" DESC - LIMIT ${LIMIT}+$3)` + LIMIT ${LIMIT}+$3` ) } + // Inner union to de-dupe item-driven notifications + queries.push( + // Only record per item ID + `(SELECT DISTINCT ON (id) * + FROM ( + SELECT * + FROM ( + ${itemDrivenQueries.map(q => `(${q})`).join(' UNION ALL ')} + ) as inner_union + ORDER BY id ASC, CASE + WHEN type = 'Mention' THEN 1 + WHEN type = 'Reply' THEN 2 + WHEN type = 'FollowActivity' THEN 3 + END ASC + ) as ordered_unioned)` + ) queries.push( `(SELECT "Item".id::text, "Item"."statusUpdatedAt" AS "sortTime", NULL as "earnedSats",