-
Notifications
You must be signed in to change notification settings - Fork 554
/
20230523T183902064Z-algo-whats-hot-view.ts
92 lines (81 loc) · 2.73 KB
/
20230523T183902064Z-algo-whats-hot-view.ts
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
import { Kysely, sql } from 'kysely'
import { Dialect } from '..'
export async function up(db: Kysely<any>, dialect: Dialect): Promise<void> {
if (dialect !== 'pg') return
const { ref } = db.dynamic
// materialized views are difficult to change,
// so we parameterize them at runtime with contents of this table.
await db.schema
.createTable('view_param')
.addColumn('name', 'varchar', (col) => col.primaryKey())
.addColumn('value', 'varchar')
.execute()
await db
.insertInto('view_param')
.values([
{ name: 'whats_hot_like_threshold', value: '10' },
{ name: 'whats_hot_interval', value: '1day' },
])
.execute()
// define view query for whats-hot feed
// tldr: scored by like count depreciated over time.
// From: https://medium.com/hacking-and-gonzo/how-hacker-news-ranking-algorithm-works-1d9b0cf2c08d
// Score = (P-1) / (T+2)^G
// where,
// P = points of an item (and -1 is to negate submitters vote)
// T = time since submission (in hours)
// G = Gravity, defaults to 1.8 in news.arc
const likeCount = ref('post_agg.likeCount')
const indexedAt = ref('post.indexedAt')
const computeScore = sql<number>`round(1000000 * (${likeCount} / ((EXTRACT(epoch FROM AGE(now(), ${indexedAt}::timestamp)) / 3600 + 2) ^ 1.8)))`
const viewQb = db
.selectFrom('post')
.innerJoin('post_agg', 'post_agg.uri', 'post.uri')
.where(
'post.indexedAt',
'>',
db
.selectFrom('view_param')
.where('name', '=', 'whats_hot_interval')
.select(
sql`to_char(now() - value::interval, 'YYYY-MM-DD"T"HH24:MI:SS.MS"Z"')`.as(
'val',
),
),
)
.where('post.replyParent', 'is', null)
.where(
'post_agg.likeCount',
'>',
db // helps cull result set that needs to be sorted
.selectFrom('view_param')
.where('name', '=', 'whats_hot_like_threshold')
.select(sql`value::integer`.as('val')),
)
.select(['post.uri as uri', 'post.cid as cid', computeScore.as('score')])
await db.schema
.createView('algo_whats_hot_view')
.materialized()
.as(viewQb)
.execute()
// unique index required for pg to refresh view w/ "concurrently" param.
await db.schema
.createIndex('algo_whats_hot_view_uri_idx')
.on('algo_whats_hot_view')
.column('uri')
.unique()
.execute()
await db.schema
.createIndex('algo_whats_hot_view_cursor_idx')
.on('algo_whats_hot_view')
.columns(['score', 'cid'])
.execute()
}
export async function down(
db: Kysely<unknown>,
dialect: Dialect,
): Promise<void> {
if (dialect !== 'pg') return
await db.schema.dropView('algo_whats_hot_view').materialized().execute()
await db.schema.dropTable('view_param').execute()
}