Skip to content

Commit

Permalink
Merge pull request #4253 from thematters/develop
Browse files Browse the repository at this point in the history
Release: v5.6.2
  • Loading branch information
gitwoz authored Dec 16, 2024
2 parents 26c3485 + 2950c3e commit ce9704c
Show file tree
Hide file tree
Showing 4 changed files with 82 additions and 71 deletions.
65 changes: 65 additions & 0 deletions db/migrations/20241215231406_tag_related_authors_view.js
Original file line number Diff line number Diff line change
@@ -0,0 +1,65 @@
const table = 'tag_related_authors_materialized'

exports.up = async (knex) => {
await knex.raw(`
CREATE MATERIALIZED VIEW ${table} AS
WITH active_articles AS (
SELECT
article.author_id,
article.id as article_id,
at.tag_id
FROM article_tag as at
INNER JOIN article ON article.id = at.article_id
INNER JOIN "user" as u ON u.id = article.author_id
WHERE article.state = 'active'
AND u.state NOT IN ('frozen', 'archived')
AND u.id NOT IN (SELECT user_id FROM user_restriction)
),
author_stats AS (
SELECT
a.tag_id,
a.author_id,
avg(COALESCE(s.reads, 0)) as mean_reads,
avg(COALESCE(s.claps, 0)) as mean_claps
FROM active_articles as a
LEFT JOIN article_stats_materialized as s ON s.article_id = a.article_id
GROUP BY a.tag_id, a.author_id
),
author_scores AS (
SELECT
tag_id,
author_id,
mean_reads,
mean_claps,
(0.85 * mean_reads + 0.15 * mean_claps) as score
FROM author_stats
),
tag_thresholds AS (
SELECT
tag_id,
percentile_cont(0.25) WITHIN GROUP (ORDER BY score) as threshold
FROM author_scores
GROUP BY tag_id
)
SELECT
author_scores.tag_id,
u.id as author_id,
author_scores.score
FROM author_scores
INNER JOIN "user" as u ON u.id = author_scores.author_id
INNER JOIN tag_thresholds t ON t.tag_id = author_scores.tag_id
WHERE author_scores.score > t.threshold
`)

await knex.raw(`
CREATE UNIQUE INDEX ${table}_tag_author ON ${table} (tag_id, author_id)
`)

await knex.raw(`
CREATE INDEX ${table}_tag_id ON ${table} (tag_id)
`)
}

exports.down = async (knex) => {
await knex.raw(`DROP MATERIALIZED VIEW IF EXISTS ${table} CASCADE`)
}
2 changes: 1 addition & 1 deletion package.json
Original file line number Diff line number Diff line change
@@ -1,6 +1,6 @@
{
"name": "matters-server",
"version": "5.6.1",
"version": "5.6.2",
"description": "Matters Server",
"author": "Matters <[email protected]>",
"main": "build/index.js",
Expand Down
1 change: 1 addition & 0 deletions src/common/enums/table.ts
Original file line number Diff line number Diff line change
Expand Up @@ -10,6 +10,7 @@ export enum MATERIALIZED_VIEW {
tags_lasts_view_materialized = 'mat_views.tags_lasts_view_materialized',
tag_stats_materialized = 'tag_stats_materialized',
tag_hottest_materialized = 'tag_hottest_materialized',
tag_related_authors_materialized = 'tag_related_authors_materialized',
article_stats_materialized = 'article_stats_materialized',
user_reader_materialized = 'user_reader_materialized',
featured_comment_materialized = 'featured_comment_materialized',
Expand Down
85 changes: 15 additions & 70 deletions src/connectors/tagService.ts
Original file line number Diff line number Diff line change
Expand Up @@ -729,70 +729,6 @@ export class TagService extends BaseService<Tag> {
/**
* Find related authors by tag id
*/
private getRelatedAuthorsQuery = (tagId: string) => {
return this.knex
.with('active_articles', (builder) =>
builder
.select('article.author_id', 'article.id as article_id')
.from('article_tag as at')
.innerJoin('article', 'article.id', 'at.article_id')
.innerJoin('user as u', 'u.id', 'article.author_id')
.where({
'at.tag_id': tagId,
'article.state': ARTICLE_STATE.active,
})
.whereNotIn('u.state', ['frozen', 'archived'])
.whereNotIn(
'u.id',
this.knex.select('user_id').from('user_restriction')
)
)
.with('author_stats', (builder) =>
builder
.select(
'a.author_id',
this.knex.raw('avg(COALESCE(s.reads, 0)) as mean_reads'),
this.knex.raw('avg(COALESCE(s.claps, 0)) as mean_claps')
)
.from('active_articles as a')
.leftJoin(
'article_stats_materialized as s',
's.article_id',
'a.article_id'
)
.groupBy('a.author_id')
)
.with('author_scores', (builder) =>
builder
.select(
'author_id',
'mean_reads',
'mean_claps',
this.knex.raw('(0.85 * mean_reads + 0.15 * mean_claps) as score')
)
.from('author_stats')
)
.with('score_threshold', (builder) =>
builder
.select(
this.knex.raw(
'percentile_cont(0.25) within group (order by score) as threshold'
)
)
.from('author_scores')
)
.select(['u.id', 'author_scores.score'])
.from('author_scores')
.innerJoin('user as u', 'u.id', 'author_scores.author_id')
.where(
'author_scores.score',
'>',
this.knex.select('threshold').from('score_threshold')
)
.groupBy(['u.id', 'author_scores.score'])
.orderBy('author_scores.score', 'desc')
}

public findRelatedAuthors = async ({
id: tagId,
skip,
Expand All @@ -802,22 +738,31 @@ export class TagService extends BaseService<Tag> {
skip?: number
take?: number
}) => {
const result = await this.getRelatedAuthorsQuery(tagId).modify(
(builder: Knex.QueryBuilder) => {
const result = await this.knex
.select('author_id as id')
.from(MATERIALIZED_VIEW.tag_related_authors_materialized)
.where({ tagId })
.orderBy('score', 'desc')
.modify((builder: Knex.QueryBuilder) => {
if (skip !== undefined && Number.isFinite(skip)) {
builder.offset(skip)
}
if (take !== undefined && Number.isFinite(take)) {
builder.limit(take)
}
}
)
})

return result.map(({ id }: { id: string }) => id)
}

public countRelatedAuthors = async ({ id: tagId }: { id: string }) => {
const result = await this.getRelatedAuthorsQuery(tagId)
return result.length
const result = await this.knex
.count()
.from(MATERIALIZED_VIEW.tag_related_authors_materialized)
.where({ tagId })
.first()

return parseInt(result ? (result.count as string) : '0', 10)
}

/**
Expand Down

0 comments on commit ce9704c

Please sign in to comment.