improve perf of rank view perf
This commit is contained in:
parent
28263bc6c7
commit
0de134309c
@ -361,10 +361,10 @@ export default {
|
|||||||
FROM "Item"
|
FROM "Item"
|
||||||
${await joinSatRankView(me, models)}
|
${await joinSatRankView(me, models)}
|
||||||
${subClause(sub, 2, 'Item', true)}
|
${subClause(sub, 2, 'Item', true)}
|
||||||
ORDER BY rank DESC NULLS LAST, id DESC
|
ORDER BY rank ASC
|
||||||
OFFSET $1
|
OFFSET $1
|
||||||
LIMIT ${LIMIT}`,
|
LIMIT ${LIMIT}`,
|
||||||
orderBy: 'ORDER BY rank DESC NULLS LAST, id DESC'
|
orderBy: 'ORDER BY rank ASC'
|
||||||
}, decodedCursor.offset, ...subArr)
|
}, decodedCursor.offset, ...subArr)
|
||||||
|
|
||||||
if (decodedCursor.offset === 0) {
|
if (decodedCursor.offset === 0) {
|
||||||
|
58
prisma/migrations/20230524062059_rank_again/migration.sql
Normal file
58
prisma/migrations/20230524062059_rank_again/migration.sql
Normal file
@ -0,0 +1,58 @@
|
|||||||
|
-- our last attempt was slow because nearly every row had to change given
|
||||||
|
-- that we store the score and all other columns rather than the rank ...
|
||||||
|
-- the score always changes and other columns are denormalized (and also change) ..
|
||||||
|
-- if instead we just store the rank, concurrent refreshes should be faster
|
||||||
|
-- as they'll be near identical
|
||||||
|
-- we also limit the view to 2100 rows which is more than any reasonable person would view
|
||||||
|
DROP MATERIALIZED VIEW IF EXISTS sat_rank_wwm_view;
|
||||||
|
CREATE MATERIALIZED VIEW IF NOT EXISTS sat_rank_wwm_view AS
|
||||||
|
SELECT id, row_number() OVER (ORDER BY
|
||||||
|
((GREATEST("weightedVotes", POWER("weightedVotes", 1.2)) + "weightedComments"/2)
|
||||||
|
/
|
||||||
|
POWER(GREATEST(3, EXTRACT(EPOCH FROM (now_utc() - created_at))/3600), 1.3)
|
||||||
|
+
|
||||||
|
(boost/5000::float)
|
||||||
|
/
|
||||||
|
POWER(EXTRACT(EPOCH FROM (now_utc() - created_at))/3600+2, 2.6)) DESC NULLS LAST, id DESC) as rank
|
||||||
|
FROM "Item"
|
||||||
|
WHERE "parentId" IS NULL AND NOT bio AND "pinId" IS NULL AND "deletedAt" IS NULL
|
||||||
|
AND "weightedVotes" > 0
|
||||||
|
ORDER BY
|
||||||
|
((GREATEST("weightedVotes", POWER("weightedVotes", 1.2)) + "weightedComments"/2)
|
||||||
|
/
|
||||||
|
POWER(GREATEST(3, EXTRACT(EPOCH FROM (now_utc() - created_at))/3600), 1.3)
|
||||||
|
+
|
||||||
|
(boost/5000::float)
|
||||||
|
/
|
||||||
|
POWER(EXTRACT(EPOCH FROM (now_utc() - created_at))/3600+2, 2.6)) DESC NULLS LAST, id DESC
|
||||||
|
LIMIT 2100;
|
||||||
|
|
||||||
|
CREATE UNIQUE INDEX IF NOT EXISTS sat_rank_wwm_view_idx ON sat_rank_wwm_view(rank ASC);
|
||||||
|
|
||||||
|
-- we do the same for the tender view
|
||||||
|
DROP MATERIALIZED VIEW IF EXISTS sat_rank_tender_view;
|
||||||
|
CREATE MATERIALIZED VIEW IF NOT EXISTS sat_rank_tender_view AS
|
||||||
|
SELECT id, row_number() OVER (ORDER BY
|
||||||
|
((GREATEST(ABS("weightedVotes" - "weightedDownVotes"), POWER(ABS("weightedVotes" - "weightedDownVotes"), 1.2))
|
||||||
|
+ "weightedComments"/2)
|
||||||
|
/
|
||||||
|
POWER(GREATEST(3, EXTRACT(EPOCH FROM (now_utc() - created_at))/3600), 1.3)
|
||||||
|
+
|
||||||
|
(boost/5000::float)
|
||||||
|
/
|
||||||
|
POWER(EXTRACT(EPOCH FROM (now_utc() - created_at))/3600+2, 2.6)) DESC NULLS LAST, id DESC) AS rank
|
||||||
|
FROM "Item"
|
||||||
|
WHERE "parentId" IS NULL AND NOT bio AND "pinId" IS NULL AND "deletedAt" IS NULL
|
||||||
|
AND "weightedVotes" > "weightedDownVotes"
|
||||||
|
ORDER BY
|
||||||
|
((GREATEST(ABS("weightedVotes" - "weightedDownVotes"), POWER(ABS("weightedVotes" - "weightedDownVotes"), 1.2))
|
||||||
|
+ "weightedComments"/2)
|
||||||
|
/
|
||||||
|
POWER(GREATEST(3, EXTRACT(EPOCH FROM (now_utc() - created_at))/3600), 1.3)
|
||||||
|
+
|
||||||
|
(boost/5000::float)
|
||||||
|
/
|
||||||
|
POWER(EXTRACT(EPOCH FROM (now_utc() - created_at))/3600+2, 2.6)) DESC NULLS LAST, id DESC
|
||||||
|
LIMIT 2100;
|
||||||
|
|
||||||
|
CREATE UNIQUE INDEX IF NOT EXISTS sat_rank_tender_view_idx ON sat_rank_tender_view(rank ASC);
|
Loading…
x
Reference in New Issue
Block a user