fix: inefficient SQL query for getting songs close to milestone
This commit is contained in:
parent
8158ce10c0
commit
fabb77d98d
@ -5,40 +5,31 @@ import { parseTimestampFromPsql } from "lib/utils/formatTimestampToPostgre.ts";
|
||||
|
||||
export async function getSongsNearMilestone(client: Client) {
|
||||
const queryResult = await client.queryObject<VideoSnapshotType>(`
|
||||
WITH max_views_per_aid AS (
|
||||
-- 找出每个 aid 的最大 views 值,并确保 aid 存在于 songs 表中
|
||||
WITH filtered_snapshots AS (
|
||||
SELECT
|
||||
vs.aid,
|
||||
MAX(vs.views) AS max_views
|
||||
vs.*
|
||||
FROM
|
||||
video_snapshot vs
|
||||
INNER JOIN
|
||||
songs s
|
||||
ON
|
||||
vs.aid = s.aid
|
||||
GROUP BY
|
||||
vs.aid
|
||||
),
|
||||
filtered_max_views AS (
|
||||
-- 筛选出满足条件的最大 views
|
||||
SELECT
|
||||
aid,
|
||||
max_views
|
||||
FROM
|
||||
max_views_per_aid
|
||||
WHERE
|
||||
(max_views >= 90000 AND max_views < 100000) OR
|
||||
(max_views >= 900000 AND max_views < 1000000)
|
||||
(vs.views >= 90000 AND vs.views < 100000) OR
|
||||
(vs.views >= 900000 AND vs.views < 1000000)
|
||||
),
|
||||
ranked_snapshots AS (
|
||||
SELECT
|
||||
fs.*,
|
||||
ROW_NUMBER() OVER (PARTITION BY fs.aid ORDER BY fs.created_at DESC) as rn,
|
||||
MAX(fs.views) OVER (PARTITION BY fs.aid) as max_views_per_aid
|
||||
FROM
|
||||
filtered_snapshots fs
|
||||
INNER JOIN
|
||||
songs s ON fs.aid = s.aid
|
||||
)
|
||||
-- 获取符合条件的完整行数据
|
||||
SELECT
|
||||
vs.*
|
||||
rs.id, rs.created_at, rs.views, rs.coins, rs.likes, rs.favorites, rs.shares, rs.danmakus, rs.aid, rs.replies
|
||||
FROM
|
||||
video_snapshot vs
|
||||
INNER JOIN
|
||||
filtered_max_views fmv
|
||||
ON
|
||||
vs.aid = fmv.aid AND vs.views = fmv.max_views
|
||||
ranked_snapshots rs
|
||||
WHERE
|
||||
rs.rn = 1;
|
||||
`);
|
||||
return queryResult.rows.map((row) => {
|
||||
return {
|
||||
|
Loading…
Reference in New Issue
Block a user