From d73d3fda74ce6cec7e5d533118424e8f4e2b134b Mon Sep 17 00:00:00 2001 From: keyan Date: Thu, 14 Sep 2023 10:46:59 -0500 Subject: [PATCH] personal wot --- api/resolvers/item.js | 161 +++++++++++----- lib/constants.js | 1 + .../20230817221949_trust_arcs/migration.sql | 14 ++ .../20231011205945_arc_to_idx/migration.sql | 2 + .../20231013002652_pwot_views/migration.sql | 181 ++++++++++++++++++ prisma/schema.prisma | 13 ++ worker/trust.js | 111 +++++++---- worker/views.js | 4 +- 8 files changed, 395 insertions(+), 92 deletions(-) create mode 100644 prisma/migrations/20230817221949_trust_arcs/migration.sql create mode 100644 prisma/migrations/20231011205945_arc_to_idx/migration.sql create mode 100644 prisma/migrations/20231013002652_pwot_views/migration.sql diff --git a/api/resolvers/item.js b/api/resolvers/item.js index 01621c60..964d7bbb 100644 --- a/api/resolvers/item.js +++ b/api/resolvers/item.js @@ -7,7 +7,8 @@ import domino from 'domino' import { ITEM_SPAM_INTERVAL, ITEM_FILTER_THRESHOLD, DONT_LIKE_THIS_COST, COMMENT_DEPTH_LIMIT, COMMENT_TYPE_QUERY, - ANON_COMMENT_FEE, ANON_USER_ID, ANON_POST_FEE, ANON_ITEM_SPAM_INTERVAL, POLL_COST + ANON_COMMENT_FEE, ANON_USER_ID, ANON_POST_FEE, ANON_ITEM_SPAM_INTERVAL, POLL_COST, + GLOBAL_SEED } from '../../lib/constants' import { msatsToSats } from '../../lib/format' import { parse } from 'tldts' @@ -36,24 +37,39 @@ export async function commentFilterClause (me, models) { return clause } -async function comments (me, models, id, sort) { - let orderBy - switch (sort) { - case 'top': - orderBy = `ORDER BY ${await orderByNumerator(me, models)} DESC, "Item".msats DESC, ("Item".freebie IS FALSE) DESC, "Item".id DESC` - break - case 'recent': - orderBy = 'ORDER BY "Item".created_at DESC, "Item".msats DESC, ("Item".freebie IS FALSE) DESC, "Item".id DESC' - break - default: - orderBy = `ORDER BY ${await orderByNumerator(me, models)}/POWER(GREATEST(3, EXTRACT(EPOCH FROM (now_utc() - "Item".created_at))/3600), 1.3) DESC NULLS LAST, "Item".msats DESC, ("Item".freebie IS FALSE) DESC, "Item".id DESC` - break +function commentsOrderByClause (me, models, sort) { + if (sort === 'recent') { + return 'ORDER BY "Item".created_at DESC, "Item".id DESC' } + if (me) { + if (sort === 'top') { + return `ORDER BY COALESCE( + personal_top_score, + ${orderByNumerator(models, 0)}) DESC NULLS LAST, + "Item".msats DESC, ("Item".freebie IS FALSE) DESC, "Item".id DESC` + } else { + return `ORDER BY COALESCE( + personal_hot_score, + ${orderByNumerator(models, 0)}/POWER(GREATEST(3, EXTRACT(EPOCH FROM (now_utc() - "Item".created_at))/3600), 1.3)) DESC NULLS LAST, + "Item".msats DESC, ("Item".freebie IS FALSE) DESC, "Item".id DESC` + } + } else { + if (sort === 'top') { + return `ORDER BY ${orderByNumerator(models, 0)} DESC NULLS LAST, "Item".msats DESC, ("Item".freebie IS FALSE) DESC, "Item".id DESC` + } else { + return `ORDER BY ${orderByNumerator(models, 0)}/POWER(GREATEST(3, EXTRACT(EPOCH FROM (now_utc() - "Item".created_at))/3600), 1.3) DESC NULLS LAST, "Item".msats DESC, ("Item".freebie IS FALSE) DESC, "Item".id DESC` + } + } +} + +async function comments (me, models, id, sort) { + const orderBy = commentsOrderByClause(me, models, sort) + const filter = await commentFilterClause(me, models) if (me) { - const [{ item_comments_with_me: comments }] = await models.$queryRawUnsafe( - 'SELECT item_comments_with_me($1::INTEGER, $2::INTEGER, $3::INTEGER, $4, $5)', Number(id), Number(me.id), COMMENT_DEPTH_LIMIT, filter, orderBy) + const [{ item_comments_zaprank_with_me: comments }] = await models.$queryRawUnsafe( + 'SELECT item_comments_zaprank_with_me($1::INTEGER, $2::INTEGER, $3::INTEGER, $4::INTEGER, $5, $6)', Number(id), GLOBAL_SEED, Number(me.id), COMMENT_DEPTH_LIMIT, filter, orderBy) return comments } @@ -74,43 +90,35 @@ export async function getItem (parent, { id }, { me, models }) { return item } -const orderByClause = async (by, me, models, type) => { +const orderByClause = (by, me, models, type) => { switch (by) { case 'comments': return 'ORDER BY "Item".ncomments DESC' case 'sats': return 'ORDER BY "Item".msats DESC' case 'zaprank': - return await topOrderByWeightedSats(me, models) + return topOrderByWeightedSats(me, models) default: return `ORDER BY ${type === 'bookmarks' ? '"bookmarkCreatedAt"' : '"Item".created_at'} DESC` } } -export async function orderByNumerator (me, models) { - if (me) { - const user = await models.user.findUnique({ where: { id: me.id } }) - if (user.wildWestMode) { - return '(GREATEST("Item"."weightedVotes", POWER("Item"."weightedVotes", 1.2)) + "Item"."weightedComments"/2)' - } - } - - return `(CASE WHEN "Item"."weightedVotes" > "Item"."weightedDownVotes" - THEN 1 - ELSE -1 END - * GREATEST(ABS("Item"."weightedVotes" - "Item"."weightedDownVotes"), POWER(ABS("Item"."weightedVotes" - "Item"."weightedDownVotes"), 1.2)) - + "Item"."weightedComments"/2)` +export function orderByNumerator (models, commentScaler = 0.5) { + return `(CASE WHEN "Item"."weightedVotes" - "Item"."weightedDownVotes" > 0 THEN + GREATEST("Item"."weightedVotes" - "Item"."weightedDownVotes", POWER("Item"."weightedVotes" - "Item"."weightedDownVotes", 1.2)) + ELSE + "Item"."weightedVotes" - "Item"."weightedDownVotes" + END + "Item"."weightedComments"*${commentScaler})` } -export async function joinSatRankView (me, models) { +export function joinZapRankPersonalView (me, models) { + let join = ` JOIN zap_rank_personal_view g ON g.id = "Item".id AND g."viewerId" = ${GLOBAL_SEED} ` + if (me) { - const user = await models.user.findUnique({ where: { id: me.id } }) - if (user.wildWestMode) { - return 'JOIN zap_rank_wwm_view ON "Item".id = zap_rank_wwm_view.id' - } + join += ` LEFT JOIN zap_rank_personal_view l ON l.id = g.id AND l."viewerId" = ${me.id} ` } - return 'JOIN zap_rank_tender_view ON "Item".id = zap_rank_tender_view.id' + return join } // this grabs all the stuff we need to display the item list and only @@ -347,10 +355,10 @@ export default { await filterClause(me, models, type), typeClause(type), whenClause(when || 'forever', type))} - ${await orderByClause(by, me, models, type)} + ${orderByClause(by, me, models, type)} OFFSET $3 LIMIT $4`, - orderBy: await orderByClause(by, me, models, type) + orderBy: orderByClause(by, me, models, type) }, decodedCursor.time, user.id, decodedCursor.offset, limit, ...subArr) break case 'recent': @@ -375,10 +383,34 @@ export default { }, decodedCursor.time, decodedCursor.offset, limit, ...subArr) break case 'top': - items = await itemQueryWithMeta({ - me, - models, - query: ` + if (me && (!by || by === 'zaprank') && (when === 'day' || when === 'week')) { + // personalized zaprank only goes back 7 days + items = await itemQueryWithMeta({ + me, + models, + query: ` + ${SELECT}, GREATEST(g.tf_top_score, l.tf_top_score) AS rank + ${relationClause(type)} + ${joinZapRankPersonalView(me, models)} + ${whereClause( + '"Item".created_at <= $1', + '"Item"."pinId" IS NULL', + '"Item"."deletedAt" IS NULL', + subClause(sub, 4, subClauseTable(type)), + typeClause(type), + whenClause(when, type), + await filterClause(me, models, type), + muteClause(me))} + ORDER BY rank DESC + OFFSET $2 + LIMIT $3`, + orderBy: 'ORDER BY rank DESC' + }, decodedCursor.time, decodedCursor.offset, limit, ...subArr) + } else { + items = await itemQueryWithMeta({ + me, + models, + query: ` ${selectClause(type)} ${relationClause(type)} ${whereClause( @@ -390,11 +422,12 @@ export default { whenClause(when, type), await filterClause(me, models, type), muteClause(me))} - ${await orderByClause(by || 'zaprank', me, models, type)} + ${orderByClause(by || 'zaprank', me, models, type)} OFFSET $2 LIMIT $3`, - orderBy: await orderByClause(by || 'zaprank', me, models, type) - }, decodedCursor.time, decodedCursor.offset, limit, ...subArr) + orderBy: orderByClause(by || 'zaprank', me, models, type) + }, decodedCursor.time, decodedCursor.offset, limit, ...subArr) + } break default: // sub so we know the default ranking @@ -433,18 +466,42 @@ export default { me, models, query: ` - ${SELECT}, rank + ${SELECT}, ${me ? 'GREATEST(g.tf_hot_score, l.tf_hot_score)' : 'g.tf_hot_score'} AS rank FROM "Item" - ${await joinSatRankView(me, models)} + ${joinZapRankPersonalView(me, models)} ${whereClause( + '"Item"."pinId" IS NULL', + '"Item"."deletedAt" IS NULL', + '"Item"."parentId" IS NULL', + '"Item".bio = false', subClause(sub, 3, 'Item', true), muteClause(me))} - ORDER BY rank ASC + ORDER BY rank DESC OFFSET $1 LIMIT $2`, - orderBy: 'ORDER BY rank ASC' + orderBy: 'ORDER BY rank DESC' }, decodedCursor.offset, limit, ...subArr) + // XXX this is just for migration purposes ... can remove after initial deployment + // and views have been populated + if (items.length === 0) { + items = await itemQueryWithMeta({ + me, + models, + query: ` + ${SELECT}, rank + FROM "Item" + JOIN zap_rank_tender_view ON "Item".id = zap_rank_tender_view.id + ${whereClause( + subClause(sub, 3, 'Item', true), + muteClause(me))} + ORDER BY rank ASC + OFFSET $1 + LIMIT $2`, + orderBy: 'ORDER BY rank ASC' + }, decodedCursor.offset, limit, ...subArr) + } + if (decodedCursor.offset === 0) { // get pins for the page and return those separately pins = await itemQueryWithMeta({ @@ -461,7 +518,7 @@ export default { FROM "Item" ${whereClause( '"pinId" IS NOT NULL', - subClause(sub, 1), + sub ? '("subName" = $1 OR "subName" IS NULL)' : '"subName" IS NULL', muteClause(me))} ) rank_filter WHERE RANK = 1` }, ...subArr) @@ -1108,6 +1165,6 @@ export const SELECT = "Item"."weightedDownVotes", "Item".freebie, "Item"."otsHash", "Item"."bountyPaidTo", ltree2text("Item"."path") AS "path", "Item"."weightedComments", "Item"."imgproxyUrls"` -async function topOrderByWeightedSats (me, models) { - return `ORDER BY ${await orderByNumerator(me, models)} DESC NULLS LAST, "Item".id DESC` +function topOrderByWeightedSats (me, models) { + return `ORDER BY ${orderByNumerator(models)} DESC NULLS LAST, "Item".id DESC` } diff --git a/lib/constants.js b/lib/constants.js index c7db9b07..19a04830 100644 --- a/lib/constants.js +++ b/lib/constants.js @@ -52,6 +52,7 @@ export const ANON_COMMENT_FEE = 100 export const SSR = typeof window === 'undefined' export const MAX_FORWARDS = 5 export const LNURLP_COMMENT_MAX_LENGTH = 1000 +export const GLOBAL_SEED = 616 export const FOUND_BLURBS = [ 'The harsh frontier is no place for the unprepared. This hat will protect you from the sun, dust, and other elements Mother Nature throws your way.', diff --git a/prisma/migrations/20230817221949_trust_arcs/migration.sql b/prisma/migrations/20230817221949_trust_arcs/migration.sql new file mode 100644 index 00000000..a152852d --- /dev/null +++ b/prisma/migrations/20230817221949_trust_arcs/migration.sql @@ -0,0 +1,14 @@ +-- CreateTable +CREATE TABLE "Arc" ( + "fromId" INTEGER NOT NULL, + "toId" INTEGER NOT NULL, + "zapTrust" DOUBLE PRECISION NOT NULL, + + CONSTRAINT "Arc_pkey" PRIMARY KEY ("fromId","toId") +); + +-- AddForeignKey +ALTER TABLE "Arc" ADD CONSTRAINT "Arc_fromId_fkey" FOREIGN KEY ("fromId") REFERENCES "users"("id") ON DELETE CASCADE ON UPDATE CASCADE; + +-- AddForeignKey +ALTER TABLE "Arc" ADD CONSTRAINT "Arc_toId_fkey" FOREIGN KEY ("toId") REFERENCES "users"("id") ON DELETE CASCADE ON UPDATE CASCADE; diff --git a/prisma/migrations/20231011205945_arc_to_idx/migration.sql b/prisma/migrations/20231011205945_arc_to_idx/migration.sql new file mode 100644 index 00000000..ee3d909c --- /dev/null +++ b/prisma/migrations/20231011205945_arc_to_idx/migration.sql @@ -0,0 +1,2 @@ +-- CreateIndex +CREATE INDEX "Arc_toId_fromId_idx" ON "Arc"("toId", "fromId"); diff --git a/prisma/migrations/20231013002652_pwot_views/migration.sql b/prisma/migrations/20231013002652_pwot_views/migration.sql new file mode 100644 index 00000000..6c383ed7 --- /dev/null +++ b/prisma/migrations/20231013002652_pwot_views/migration.sql @@ -0,0 +1,181 @@ +CREATE OR REPLACE VIEW zap_rank_personal_constants AS +SELECT +5000.0 AS boost_per_vote, +1.2 AS vote_power, +1.3 AS vote_decay, +3.0 AS age_wait_hours, +0.5 AS comment_scaler, +1.2 AS boost_power, +1.6 AS boost_decay, +616 AS global_viewer_id, +interval '7 days' AS item_age_bound, +interval '7 days' AS user_last_seen_bound, +0.9 AS max_personal_viewer_vote_ratio, +0.1 AS min_viewer_votes; + +DROP MATERIALIZED VIEW IF EXISTS zap_rank_personal_view; +CREATE MATERIALIZED VIEW IF NOT EXISTS zap_rank_personal_view AS +WITH item_votes AS ( + SELECT "Item".id, "Item"."parentId", "Item".boost, "Item".created_at, "Item"."weightedComments", "ItemAct"."userId" AS "voterId", + LOG((SUM("ItemAct".msats) FILTER (WHERE "ItemAct".act IN ('TIP', 'FEE'))) / 1000.0) AS "vote", + GREATEST(LOG((SUM("ItemAct".msats) FILTER (WHERE "ItemAct".act = 'DONT_LIKE_THIS')) / 1000.0), 0) AS "downVote" + FROM "Item" + CROSS JOIN zap_rank_personal_constants + JOIN "ItemAct" ON "ItemAct"."itemId" = "Item".id + WHERE ( + "ItemAct"."userId" <> "Item"."userId" AND "ItemAct".act IN ('TIP', 'FEE', 'DONT_LIKE_THIS') + OR "ItemAct".act = 'BOOST' AND "ItemAct"."userId" = "Item"."userId" + ) + AND "Item".created_at >= now_utc() - item_age_bound + GROUP BY "Item".id, "Item"."parentId", "Item".boost, "Item".created_at, "Item"."weightedComments", "ItemAct"."userId" + HAVING SUM("ItemAct".msats) > 1000 +), viewer_votes AS ( + SELECT item_votes.id, item_votes."parentId", item_votes.boost, item_votes.created_at, + item_votes."weightedComments", "Arc"."fromId" AS "viewerId", + GREATEST("Arc"."zapTrust", g."zapTrust", 0) * item_votes."vote" AS "weightedVote", + GREATEST("Arc"."zapTrust", g."zapTrust", 0) * item_votes."downVote" AS "weightedDownVote" + FROM item_votes + CROSS JOIN zap_rank_personal_constants + LEFT JOIN "Arc" ON "Arc"."toId" = item_votes."voterId" + LEFT JOIN "Arc" g ON g."fromId" = global_viewer_id AND g."toId" = item_votes."voterId" + AND ("Arc"."zapTrust" IS NOT NULL OR g."zapTrust" IS NOT NULL) +), viewer_weighted_votes AS ( + SELECT viewer_votes.id, viewer_votes."parentId", viewer_votes.boost, viewer_votes.created_at, viewer_votes."viewerId", + viewer_votes."weightedComments", SUM(viewer_votes."weightedVote") AS "weightedVotes", + SUM(viewer_votes."weightedDownVote") AS "weightedDownVotes" + FROM viewer_votes + GROUP BY viewer_votes.id, viewer_votes."parentId", viewer_votes.boost, viewer_votes.created_at, viewer_votes."viewerId", viewer_votes."weightedComments" +), viewer_zaprank AS ( + SELECT l.id, l."parentId", l.boost, l.created_at, l."viewerId", l."weightedComments", + GREATEST(l."weightedVotes", g."weightedVotes") AS "weightedVotes", GREATEST(l."weightedDownVotes", g."weightedDownVotes") AS "weightedDownVotes" + FROM viewer_weighted_votes l + CROSS JOIN zap_rank_personal_constants + JOIN users ON users.id = l."viewerId" + JOIN viewer_weighted_votes g ON l.id = g.id AND g."viewerId" = global_viewer_id + WHERE (l."weightedVotes" > min_viewer_votes + AND g."weightedVotes" / l."weightedVotes" <= max_personal_viewer_vote_ratio + AND users."lastSeenAt" >= now_utc() - user_last_seen_bound) + OR l."viewerId" = global_viewer_id + GROUP BY l.id, l."parentId", l.boost, l.created_at, l."viewerId", l."weightedVotes", l."weightedComments", + g."weightedVotes", l."weightedDownVotes", g."weightedDownVotes", min_viewer_votes + HAVING GREATEST(l."weightedVotes", g."weightedVotes") > min_viewer_votes OR l.boost > 0 +), viewer_fractions_zaprank AS ( + SELECT z.*, + (CASE WHEN z."weightedVotes" - z."weightedDownVotes" > 0 THEN + GREATEST(z."weightedVotes" - z."weightedDownVotes", POWER(z."weightedVotes" - z."weightedDownVotes", vote_power)) + ELSE + z."weightedVotes" - z."weightedDownVotes" + END + z."weightedComments" * CASE WHEN z."parentId" IS NULL THEN comment_scaler ELSE 0 END) AS tf_numerator, + POWER(GREATEST(age_wait_hours, EXTRACT(EPOCH FROM (now_utc() - z.created_at))/3600), vote_decay) AS decay_denominator, + (POWER(z.boost/boost_per_vote, boost_power) + / + POWER(GREATEST(age_wait_hours, EXTRACT(EPOCH FROM (now_utc() - z.created_at))/3600), boost_decay)) AS boost_addend + FROM viewer_zaprank z, zap_rank_personal_constants +) +SELECT z.id, z."parentId", z."viewerId", + COALESCE(tf_numerator, 0) / decay_denominator + boost_addend AS tf_hot_score, + COALESCE(tf_numerator, 0) AS tf_top_score +FROM viewer_fractions_zaprank z +WHERE tf_numerator > 0 OR boost_addend > 0; + +CREATE UNIQUE INDEX IF NOT EXISTS zap_rank_personal_view_viewer_id_idx ON zap_rank_personal_view("viewerId", id); +CREATE INDEX IF NOT EXISTS hot_tf_zap_rank_personal_view_idx ON zap_rank_personal_view("viewerId", tf_hot_score DESC NULLS LAST, id DESC); +CREATE INDEX IF NOT EXISTS top_tf_zap_rank_personal_view_idx ON zap_rank_personal_view("viewerId", tf_top_score DESC NULLS LAST, id DESC); + +CREATE OR REPLACE FUNCTION item_comments_zaprank_with_me(_item_id int, _global_seed int, _me_id int, _level int, _where text, _order_by text) + RETURNS jsonb + LANGUAGE plpgsql VOLATILE PARALLEL SAFE AS +$$ +DECLARE + result jsonb; +BEGIN + IF _level < 1 THEN + RETURN '[]'::jsonb; + END IF; + + EXECUTE 'CREATE TEMP TABLE IF NOT EXISTS t_item ON COMMIT DROP AS' + || ' SELECT "Item".*, "Item".created_at at time zone ''UTC'' AS "createdAt", "Item".updated_at at time zone ''UTC'' AS "updatedAt", ' + || ' to_jsonb(users.*) || jsonb_build_object(''meMute'', "Mute"."mutedId" IS NOT NULL) AS user, ' + || ' COALESCE("ItemAct"."meMsats", 0) AS "meMsats", COALESCE("ItemAct"."meDontLike", false) AS "meDontLike", ' + || ' "Bookmark"."itemId" IS NOT NULL AS "meBookmark", "ThreadSubscription"."itemId" IS NOT NULL AS "meSubscription", ' + || ' GREATEST(g.tf_hot_score, l.tf_hot_score) AS personal_hot_score, GREATEST(g.tf_top_score, l.tf_top_score) AS personal_top_score ' + || ' FROM "Item" ' + || ' JOIN users ON users.id = "Item"."userId" ' + || ' LEFT JOIN "Mute" ON "Mute"."muterId" = $5 AND "Mute"."mutedId" = "Item"."userId"' + || ' LEFT JOIN "Bookmark" ON "Bookmark"."userId" = $5 AND "Bookmark"."itemId" = "Item".id ' + || ' LEFT JOIN "ThreadSubscription" ON "ThreadSubscription"."userId" = $5 AND "ThreadSubscription"."itemId" = "Item".id ' + || ' LEFT JOIN LATERAL ( ' + || ' SELECT "itemId", sum("ItemAct".msats) FILTER (WHERE act = ''FEE'' OR act = ''TIP'') AS "meMsats", ' + || ' bool_or(act = ''DONT_LIKE_THIS'') AS "meDontLike" ' + || ' FROM "ItemAct" ' + || ' WHERE "ItemAct"."userId" = $5 ' + || ' AND "ItemAct"."itemId" = "Item".id ' + || ' GROUP BY "ItemAct"."itemId" ' + || ' ) "ItemAct" ON true ' + || ' LEFT JOIN zap_rank_personal_view g ON g."viewerId" = $6 AND g.id = "Item".id ' + || ' LEFT JOIN zap_rank_personal_view l ON l."viewerId" = $5 AND l.id = g.id ' + || ' WHERE "Item".path <@ $1::TEXT::LTREE ' || _where || ' ' + USING _item_id, _level, _where, _order_by, _me_id, _global_seed; + + EXECUTE '' + || 'SELECT COALESCE(jsonb_agg(sub), ''[]''::jsonb) AS comments ' + || 'FROM ( ' + || ' SELECT "Item".*, item_comments_zaprank_with_me("Item".id, $6, $5, $2 - 1, $3, $4) AS comments ' + || ' FROM t_item "Item" ' + || ' WHERE "Item"."parentId" = $1 ' + || _order_by + || ' ) sub' + INTO result USING _item_id, _level, _where, _order_by, _me_id, _global_seed; + + RETURN result; +END +$$; + +CREATE OR REPLACE FUNCTION item_comments(_item_id int, _level int, _where text, _order_by text) + RETURNS jsonb + LANGUAGE plpgsql VOLATILE PARALLEL SAFE AS +$$ +DECLARE + result jsonb; +BEGIN + IF _level < 1 THEN + RETURN '[]'::jsonb; + END IF; + + EXECUTE 'CREATE TEMP TABLE IF NOT EXISTS t_item ON COMMIT DROP AS' + || ' SELECT "Item".*, "Item".created_at at time zone ''UTC'' AS "createdAt", "Item".updated_at at time zone ''UTC'' AS "updatedAt", ' + || ' to_jsonb(users.*) as user ' + || ' FROM "Item" ' + || ' JOIN users ON users.id = "Item"."userId" ' + || ' WHERE "Item".path <@ $1::TEXT::LTREE ' || _where + USING _item_id, _level, _where, _order_by; + + EXECUTE '' + || 'SELECT COALESCE(jsonb_agg(sub), ''[]''::jsonb) AS comments ' + || 'FROM ( ' + || ' SELECT "Item".*, item_comments("Item".id, $2 - 1, $3, $4) AS comments ' + || ' FROM t_item "Item"' + || ' WHERE "Item"."parentId" = $1 ' + || _order_by + || ' ) sub' + INTO result USING _item_id, _level, _where, _order_by; + RETURN result; +END +$$; + +CREATE OR REPLACE FUNCTION update_ranked_views_jobs() +RETURNS INTEGER +LANGUAGE plpgsql +AS $$ +DECLARE +BEGIN + INSERT INTO pgboss.job (name) values ('trust'); + UPDATE pgboss.schedule SET cron = '*/5 * * * *' WHERE name = 'rankViews'; + return 0; +EXCEPTION WHEN OTHERS THEN + return 0; +END; +$$; + +SELECT update_ranked_views_jobs(); + diff --git a/prisma/schema.prisma b/prisma/schema.prisma index d0124991..4f9c6029 100644 --- a/prisma/schema.prisma +++ b/prisma/schema.prisma @@ -95,6 +95,8 @@ model User { hideIsContributor Boolean @default(false) muters Mute[] @relation("muter") muteds Mute[] @relation("muted") + ArcOut Arc[] @relation("fromUser") + ArcIn Arc[] @relation("toUser") @@index([createdAt], map: "users.created_at_index") @@index([inviteId], map: "users.inviteId_index") @@ -113,6 +115,17 @@ model Mute { @@index([mutedId, muterId]) } +model Arc { + fromId Int + fromUser User @relation("fromUser", fields: [fromId], references: [id], onDelete: Cascade) + toId Int + toUser User @relation("toUser", fields: [toId], references: [id], onDelete: Cascade) + zapTrust Float + + @@id([fromId, toId]) + @@index([toId, fromId]) +} + model Streak { id Int @id @default(autoincrement()) createdAt DateTime @default(now()) @map("created_at") diff --git a/worker/trust.js b/worker/trust.js index b5b743a6..6dd26096 100644 --- a/worker/trust.js +++ b/worker/trust.js @@ -8,13 +8,14 @@ export function trust ({ boss, models }) { console.timeLog('trust', 'getting graph') const graph = await getGraph(models) console.timeLog('trust', 'computing trust') - const trust = await trustGivenGraph(graph) + const [vGlobal, mPersonal] = await trustGivenGraph(graph) console.timeLog('trust', 'storing trust') - await storeTrust(models, trust) - console.timeEnd('trust') + await storeTrust(models, graph, vGlobal, mPersonal) } catch (e) { console.error(e) throw e + } finally { + console.timeEnd('trust') } } } @@ -28,9 +29,11 @@ const DISAGREE_MULT = 10 // https://en.wikipedia.org/wiki/Normal_distribution#Quantile_function const Z_CONFIDENCE = 6.109410204869 // 99.9999999% confidence const SEEDS = [616, 6030, 946, 4502] +const GLOBAL_ROOT = 616 const SEED_WEIGHT = 0.25 const AGAINST_MSAT_MIN = 1000 const MSAT_MIN = 1000 +const SIG_DIFF = 0.1 // need to differ by at least 10 percent /* Given a graph and start this function returns an object where @@ -38,7 +41,7 @@ const MSAT_MIN = 1000 */ function trustGivenGraph (graph) { // empty matrix of proper size nstackers x nstackers - const mat = math.zeros(graph.length, graph.length, 'sparse') + let mat = math.zeros(graph.length, graph.length, 'sparse') // create a map of user id to position in matrix const posByUserId = {} @@ -69,34 +72,45 @@ function trustGivenGraph (graph) { matT = math.add(math.multiply(1 - SEED_WEIGHT, matT), math.multiply(SEED_WEIGHT, original)) } - console.timeLog('trust', 'normalizing result') - // we normalize the result taking the z-score, then min-max to [0,1] - // we remove seeds and 0 trust people from the result because they are known outliers - // but we need to keep them in the result to keep positions correct - function resultForId (id) { - let result = math.squeeze(math.subset(math.transpose(matT), math.index(posByUserId[id], math.range(0, graph.length)))) - const outliers = SEEDS.concat([id]) - outliers.forEach(id => result.set([posByUserId[id]], 0)) - const withoutZero = math.filter(result, val => val > 0) - // NOTE: this might be improved by using median and mad (modified z score) - // given the distribution is skewed - const mean = math.mean(withoutZero) - const std = math.std(withoutZero) - result = result.map(val => val >= 0 ? (val - mean) / std : 0) - const min = math.min(result) - const max = math.max(result) - result = math.map(result, val => (val - min) / (max - min)) - outliers.forEach(id => result.set([posByUserId[id]], MAX_TRUST)) - return result + console.timeLog('trust', 'transforming result') + + const seedIdxs = SEEDS.map(id => posByUserId[id]) + const isOutlier = (fromIdx, idx) => [...seedIdxs, fromIdx].includes(idx) + const sqapply = (mat, fn) => { + let idx = 0 + return math.squeeze(math.apply(mat, 1, d => { + const filtered = math.filter(d, (val, fidx) => { + return val !== 0 && !isOutlier(idx, fidx[0]) + }) + idx++ + if (filtered.length === 0) return 0 + return fn(filtered) + })) } - // turn the result vector into an object - const result = {} - resultForId(616).forEach((val, idx) => { - result[graph[idx].id] = val + console.timeLog('trust', 'normalizing') + console.timeLog('trust', 'stats') + mat = math.transpose(matT) + const std = sqapply(mat, math.std) // math.squeeze(math.std(mat, 1)) + const mean = sqapply(mat, math.mean) // math.squeeze(math.mean(mat, 1)) + const zscore = math.map(mat, (val, idx) => { + const zstd = math.subset(std, math.index(idx[0])) + const zmean = math.subset(mean, math.index(idx[0])) + return zstd ? (val - zmean) / zstd : 0 }) + console.timeLog('trust', 'minmax') + const min = sqapply(zscore, math.min) // math.squeeze(math.min(zscore, 1)) + const max = sqapply(zscore, math.max) // math.squeeze(math.max(zscore, 1)) + const mPersonal = math.map(zscore, (val, idx) => { + const zmin = math.subset(min, math.index(idx[0])) + const zmax = math.subset(max, math.index(idx[0])) + const zrange = zmax - zmin + if (val > zmax) return MAX_TRUST + return zrange ? (val - zmin) / zrange : 0 + }) + const vGlobal = math.squeeze(math.row(mPersonal, posByUserId[GLOBAL_ROOT])) - return result + return [vGlobal, mPersonal] } /* @@ -108,7 +122,7 @@ function trustGivenGraph (graph) { */ async function getGraph (models) { return await models.$queryRaw` - SELECT id, array_agg(json_build_object( + SELECT id, json_agg(json_build_object( 'node', oid, 'trust', CASE WHEN total_trust > 0 THEN trust / total_trust::float ELSE 0 END)) AS hops FROM ( @@ -144,9 +158,12 @@ async function getGraph (models) { FROM user_pair WHERE b_id <> ANY (${SEEDS}) UNION ALL - SELECT a_id AS id, seed_id AS oid, ${MAX_TRUST}::numeric/ARRAY_LENGTH(${SEEDS}::int[], 1) as trust + SELECT a_id AS id, seed_id AS oid, ${MAX_TRUST}::numeric as trust FROM user_pair, unnest(${SEEDS}::int[]) seed_id GROUP BY a_id, a_total, seed_id + UNION ALL + SELECT a_id AS id, a_id AS oid, ${MAX_TRUST}::float as trust + FROM user_pair ) SELECT id, oid, trust, sum(trust) OVER (PARTITION BY id) AS total_trust FROM trust_pairs @@ -155,13 +172,24 @@ async function getGraph (models) { ORDER BY id ASC` } -async function storeTrust (models, nodeTrust) { +async function storeTrust (models, graph, vGlobal, mPersonal) { // convert nodeTrust into table literal string - let values = '' - for (const [id, trust] of Object.entries(nodeTrust)) { - if (values) values += ',' - values += `(${id}, ${trust})` - } + let globalValues = '' + let personalValues = '' + vGlobal.forEach((val, [idx]) => { + if (isNaN(val)) return + if (globalValues) globalValues += ',' + globalValues += `(${graph[idx].id}, ${val}::FLOAT)` + if (personalValues) personalValues += ',' + personalValues += `(${GLOBAL_ROOT}, ${graph[idx].id}, ${val}::FLOAT)` + }) + + math.forEach(mPersonal, (val, [fromIdx, toIdx]) => { + const globalVal = vGlobal.get([toIdx]) + if (isNaN(val) || val - globalVal <= SIG_DIFF) return + if (personalValues) personalValues += ',' + personalValues += `(${graph[fromIdx].id}, ${graph[toIdx].id}, ${val}::FLOAT)` + }) // update the trust of each user in graph await models.$transaction([ @@ -169,6 +197,13 @@ async function storeTrust (models, nodeTrust) { models.$executeRawUnsafe( `UPDATE users SET trust = g.trust - FROM (values ${values}) g(id, trust) - WHERE users.id = g.id`)]) + FROM (values ${globalValues}) g(id, trust) + WHERE users.id = g.id`), + models.$executeRawUnsafe( + `INSERT INTO "Arc" ("fromId", "toId", "zapTrust") + SELECT id, oid, trust + FROM (values ${personalValues}) g(id, oid, trust) + ON CONFLICT ("fromId", "toId") DO UPDATE SET "zapTrust" = EXCLUDED."zapTrust"` + ) + ]) } diff --git a/worker/views.js b/worker/views.js index 782adffc..3f1ad86c 100644 --- a/worker/views.js +++ b/worker/views.js @@ -13,12 +13,12 @@ export function views ({ models }) { } } -// this should be run regularly ... like, every 1-5 minutes +// this should be run regularly ... like, every 5 minutes export function rankViews ({ models }) { return async function () { console.log('refreshing rank views') - for (const view of ['zap_rank_wwm_view', 'zap_rank_tender_view']) { + for (const view of ['zap_rank_personal_view']) { await models.$queryRawUnsafe(`REFRESH MATERIALIZED VIEW CONCURRENTLY ${view}`) }