use mat views (tm) for historicals (tm)
This commit is contained in:
parent
0a3f5fd201
commit
f6ab939bcc
@ -27,6 +27,29 @@ export function within (table, within) {
|
|||||||
return interval
|
return interval
|
||||||
}
|
}
|
||||||
|
|
||||||
|
export function viewWithin (table, within) {
|
||||||
|
let interval = ' AND "' + table + '".day >= date_trunc(\'day\', timezone(\'America/Chicago\', $1 at time zone \'UTC\' - interval '
|
||||||
|
switch (within) {
|
||||||
|
case 'day':
|
||||||
|
interval += "'1 day'))"
|
||||||
|
break
|
||||||
|
case 'week':
|
||||||
|
interval += "'7 days'))"
|
||||||
|
break
|
||||||
|
case 'month':
|
||||||
|
interval += "'1 month'))"
|
||||||
|
break
|
||||||
|
case 'year':
|
||||||
|
interval += "'1 year'))"
|
||||||
|
break
|
||||||
|
default:
|
||||||
|
// HACK: we need to use the time parameter otherwise prisma *cries* about it
|
||||||
|
interval = ' AND users.created_at <= $1'
|
||||||
|
break
|
||||||
|
}
|
||||||
|
return interval
|
||||||
|
}
|
||||||
|
|
||||||
export function withinDate (within) {
|
export function withinDate (within) {
|
||||||
switch (within) {
|
switch (within) {
|
||||||
case 'day':
|
case 'day':
|
||||||
@ -96,9 +119,13 @@ export default {
|
|||||||
topCowboys: async (parent, { cursor }, { models, me }) => {
|
topCowboys: async (parent, { cursor }, { models, me }) => {
|
||||||
const decodedCursor = decodeCursor(cursor)
|
const decodedCursor = decodeCursor(cursor)
|
||||||
const users = await models.$queryRaw(`
|
const users = await models.$queryRaw(`
|
||||||
SELECT users.*
|
SELECT users.*, floor(sum(msats_spent)/1000) as spent,
|
||||||
|
sum(posts) as nitems, sum(comments) as ncomments, sum(referrals) as referrals,
|
||||||
|
floor(sum(msats_stacked)/1000) as stacked
|
||||||
FROM users
|
FROM users
|
||||||
|
LEFT JOIN user_stats_days on users.id = user_stats_days.id
|
||||||
WHERE NOT "hideFromTopUsers" AND NOT "hideCowboyHat" AND streak IS NOT NULL
|
WHERE NOT "hideFromTopUsers" AND NOT "hideCowboyHat" AND streak IS NOT NULL
|
||||||
|
GROUP BY users.id
|
||||||
ORDER BY streak DESC, created_at ASC
|
ORDER BY streak DESC, created_at ASC
|
||||||
OFFSET $1
|
OFFSET $1
|
||||||
LIMIT ${LIMIT}`, decodedCursor.offset)
|
LIMIT ${LIMIT}`, decodedCursor.offset)
|
||||||
@ -110,6 +137,39 @@ export default {
|
|||||||
topUsers: async (parent, { cursor, when, sort }, { models, me }) => {
|
topUsers: async (parent, { cursor, when, sort }, { models, me }) => {
|
||||||
const decodedCursor = decodeCursor(cursor)
|
const decodedCursor = decodeCursor(cursor)
|
||||||
let users
|
let users
|
||||||
|
|
||||||
|
if (when !== 'day') {
|
||||||
|
let column
|
||||||
|
switch (sort) {
|
||||||
|
case 'spent': column = 'spent'; break
|
||||||
|
case 'posts': column = 'nitems'; break
|
||||||
|
case 'comments': column = 'ncomments'; break
|
||||||
|
case 'referrals': column = 'referrals'; break
|
||||||
|
default: column = 'stacked'; break
|
||||||
|
}
|
||||||
|
|
||||||
|
users = await models.$queryRaw(`
|
||||||
|
WITH u AS (
|
||||||
|
SELECT users.*, floor(sum(msats_spent)/1000) as spent,
|
||||||
|
sum(posts) as nitems, sum(comments) as ncomments, sum(referrals) as referrals,
|
||||||
|
floor(sum(msats_stacked)/1000) as stacked
|
||||||
|
FROM user_stats_days
|
||||||
|
JOIN users on users.id = user_stats_days.id
|
||||||
|
WHERE NOT users."hideFromTopUsers"
|
||||||
|
${viewWithin('user_stats_days', when)}
|
||||||
|
GROUP BY users.id
|
||||||
|
ORDER BY ${column} DESC NULLS LAST, users.created_at DESC
|
||||||
|
)
|
||||||
|
SELECT * FROM u WHERE ${column} > 0
|
||||||
|
OFFSET $2
|
||||||
|
LIMIT ${LIMIT}`, decodedCursor.time, decodedCursor.offset)
|
||||||
|
|
||||||
|
return {
|
||||||
|
cursor: users.length === LIMIT ? nextCursorEncoded(decodedCursor) : null,
|
||||||
|
users
|
||||||
|
}
|
||||||
|
}
|
||||||
|
|
||||||
if (sort === 'spent') {
|
if (sort === 'spent') {
|
||||||
users = await models.$queryRaw(`
|
users = await models.$queryRaw(`
|
||||||
SELECT users.*, sum(sats_spent) as spent
|
SELECT users.*, sum(sats_spent) as spent
|
||||||
@ -210,11 +270,12 @@ export default {
|
|||||||
// check if any votes have been cast for them since checkedNotesAt
|
// check if any votes have been cast for them since checkedNotesAt
|
||||||
if (user.noteItemSats) {
|
if (user.noteItemSats) {
|
||||||
const votes = await models.$queryRaw(`
|
const votes = await models.$queryRaw(`
|
||||||
SELECT "ItemAct".id, "ItemAct".created_at
|
SELECT 1
|
||||||
FROM "Item"
|
FROM "Item"
|
||||||
JOIN "ItemAct" on "ItemAct"."itemId" = "Item".id
|
JOIN "ItemAct" ON
|
||||||
WHERE "ItemAct"."userId" <> $1
|
"ItemAct"."itemId" = "Item".id
|
||||||
AND "ItemAct".created_at > $2
|
AND "ItemAct"."userId" <> "Item"."userId"
|
||||||
|
WHERE "ItemAct".created_at > $2
|
||||||
AND "Item"."userId" = $1
|
AND "Item"."userId" = $1
|
||||||
AND "ItemAct".act = 'TIP'
|
AND "ItemAct".act = 'TIP'
|
||||||
LIMIT 1`, me.id, lastChecked)
|
LIMIT 1`, me.id, lastChecked)
|
||||||
@ -225,11 +286,14 @@ export default {
|
|||||||
|
|
||||||
// check if they have any replies since checkedNotesAt
|
// check if they have any replies since checkedNotesAt
|
||||||
const newReplies = await models.$queryRaw(`
|
const newReplies = await models.$queryRaw(`
|
||||||
SELECT "Item".id, "Item".created_at
|
SELECT 1
|
||||||
FROM "Item"
|
FROM "Item"
|
||||||
JOIN "Item" p ON ${user.noteAllDescendants ? '"Item".path <@ p.path' : '"Item"."parentId" = p.id'}
|
JOIN "Item" p ON
|
||||||
|
"Item".created_at >= p.created_at
|
||||||
|
AND ${user.noteAllDescendants ? '"Item".path <@ p.path' : '"Item"."parentId" = p.id'}
|
||||||
|
AND "Item"."userId" <> p."userId"
|
||||||
WHERE p."userId" = $1
|
WHERE p."userId" = $1
|
||||||
AND "Item".created_at > $2 AND "Item"."userId" <> $1
|
AND "Item".created_at > $2::timestamp(3) without time zone
|
||||||
${await filterClause(me, models)}
|
${await filterClause(me, models)}
|
||||||
LIMIT 1`, me.id, lastChecked)
|
LIMIT 1`, me.id, lastChecked)
|
||||||
if (newReplies.length > 0) {
|
if (newReplies.length > 0) {
|
||||||
@ -480,9 +544,10 @@ export default {
|
|||||||
User: {
|
User: {
|
||||||
authMethods,
|
authMethods,
|
||||||
nitems: async (user, { when }, { models }) => {
|
nitems: async (user, { when }, { models }) => {
|
||||||
if (user.nitems) {
|
if (typeof user.nitems === 'number') {
|
||||||
return user.nitems
|
return user.nitems
|
||||||
}
|
}
|
||||||
|
|
||||||
return await models.item.count({
|
return await models.item.count({
|
||||||
where: {
|
where: {
|
||||||
userId: user.id,
|
userId: user.id,
|
||||||
@ -494,7 +559,7 @@ export default {
|
|||||||
})
|
})
|
||||||
},
|
},
|
||||||
ncomments: async (user, { when }, { models }) => {
|
ncomments: async (user, { when }, { models }) => {
|
||||||
if (user.ncomments) {
|
if (typeof user.ncomments === 'number') {
|
||||||
return user.ncomments
|
return user.ncomments
|
||||||
}
|
}
|
||||||
|
|
||||||
@ -509,7 +574,7 @@ export default {
|
|||||||
})
|
})
|
||||||
},
|
},
|
||||||
nbookmarks: async (user, { when }, { models }) => {
|
nbookmarks: async (user, { when }, { models }) => {
|
||||||
if (user.nBookmarks) {
|
if (typeof user.nBookmarks === 'number') {
|
||||||
return user.nBookmarks
|
return user.nBookmarks
|
||||||
}
|
}
|
||||||
|
|
||||||
@ -523,14 +588,14 @@ export default {
|
|||||||
})
|
})
|
||||||
},
|
},
|
||||||
stacked: async (user, { when }, { models }) => {
|
stacked: async (user, { when }, { models }) => {
|
||||||
if (user.stacked) {
|
if (typeof user.stacked === 'number') {
|
||||||
return user.stacked
|
return user.stacked
|
||||||
}
|
}
|
||||||
|
|
||||||
if (!when) {
|
if (!when || when === 'forever') {
|
||||||
// forever
|
// forever
|
||||||
return (user.stackedMsats && msatsToSats(user.stackedMsats)) || 0
|
return (user.stackedMsats && msatsToSats(user.stackedMsats)) || 0
|
||||||
} else {
|
} else if (when === 'day') {
|
||||||
const [{ stacked }] = await models.$queryRaw(`
|
const [{ stacked }] = await models.$queryRaw(`
|
||||||
SELECT sum(amount) as stacked
|
SELECT sum(amount) as stacked
|
||||||
FROM
|
FROM
|
||||||
@ -551,9 +616,11 @@ export default {
|
|||||||
AND "Earn".created_at >= $1)) u`, withinDate(when), Number(user.id))
|
AND "Earn".created_at >= $1)) u`, withinDate(when), Number(user.id))
|
||||||
return (stacked && msatsToSats(stacked)) || 0
|
return (stacked && msatsToSats(stacked)) || 0
|
||||||
}
|
}
|
||||||
|
|
||||||
|
return 0
|
||||||
},
|
},
|
||||||
spent: async (user, { when }, { models }) => {
|
spent: async (user, { when }, { models }) => {
|
||||||
if (user.spent) {
|
if (typeof user.spent === 'number') {
|
||||||
return user.spent
|
return user.spent
|
||||||
}
|
}
|
||||||
|
|
||||||
@ -572,6 +639,9 @@ export default {
|
|||||||
return (msats && msatsToSats(msats)) || 0
|
return (msats && msatsToSats(msats)) || 0
|
||||||
},
|
},
|
||||||
referrals: async (user, { when }, { models }) => {
|
referrals: async (user, { when }, { models }) => {
|
||||||
|
if (typeof user.referrals === 'number') {
|
||||||
|
return user.referrals
|
||||||
|
}
|
||||||
return await models.user.count({
|
return await models.user.count({
|
||||||
where: {
|
where: {
|
||||||
referrerId: user.id,
|
referrerId: user.id,
|
||||||
|
@ -0,0 +1,61 @@
|
|||||||
|
-- for user top stats
|
||||||
|
CREATE MATERIALIZED VIEW IF NOT EXISTS user_stats_days AS
|
||||||
|
SELECT "userId" as id, day,
|
||||||
|
sum(msats_spent) as msats_spent,
|
||||||
|
sum(comments) as comments,
|
||||||
|
sum(posts) as posts,
|
||||||
|
sum(referrals) as referrals,
|
||||||
|
sum(msats_stacked) as msats_stacked
|
||||||
|
FROM
|
||||||
|
((SELECT "userId", sum(msats) as msats_spent, 0 as comments, 0 as posts, 0 as referrals,
|
||||||
|
0 as msats_stacked, date_trunc('day', timezone('America/Chicago', created_at at time zone 'UTC')) as day
|
||||||
|
FROM "ItemAct"
|
||||||
|
GROUP BY "userId", day)
|
||||||
|
UNION ALL
|
||||||
|
(SELECT "userId", sum(sats*1000) as msats_spent, 0 as comments, 0 as posts, 0 as referrals,
|
||||||
|
0 as msats_stacked, date_trunc('day', timezone('America/Chicago', created_at at time zone 'UTC')) as day
|
||||||
|
FROM "Donation"
|
||||||
|
GROUP BY "userId", day)
|
||||||
|
UNION ALL
|
||||||
|
(SELECT "userId", 0 as msats_spent, count("parentId") as comments, count("parentId" IS NULL) as posts,
|
||||||
|
0 as referrals, 0 as msats_stacked,
|
||||||
|
date_trunc('day', timezone('America/Chicago', created_at at time zone 'UTC')) as day
|
||||||
|
FROM "Item"
|
||||||
|
GROUP BY "userId", day)
|
||||||
|
UNION ALL
|
||||||
|
(SELECT "referrerId" as "userId", 0 as msats_spent, 0 as comments, 0 as posts, count(*) as referrals,
|
||||||
|
0 as msats_stacked, date_trunc('day', timezone('America/Chicago', created_at at time zone 'UTC')) as day
|
||||||
|
FROM users
|
||||||
|
WHERE "referrerId" IS NOT NULL
|
||||||
|
GROUP BY "userId", day)
|
||||||
|
UNION ALL
|
||||||
|
(SELECT "Item"."userId", 0 as msats_spent, 0 as comments, 0 as posts, 0 as referrals,
|
||||||
|
sum("ItemAct".msats) as msats_stacked,
|
||||||
|
date_trunc('day', timezone('America/Chicago', "ItemAct".created_at at time zone 'UTC')) as day
|
||||||
|
FROM "ItemAct"
|
||||||
|
JOIN "Item" on "ItemAct"."itemId" = "Item".id
|
||||||
|
WHERE "ItemAct".act = 'TIP'
|
||||||
|
GROUP BY "Item"."userId", day)
|
||||||
|
UNION ALL
|
||||||
|
(SELECT "userId", 0 as msats_spent, 0 as comments, 0 as posts, 0 as referrals,
|
||||||
|
sum(msats) as msats_stacked,
|
||||||
|
date_trunc('day', timezone('America/Chicago', created_at at time zone 'UTC')) as day
|
||||||
|
FROM "Earn"
|
||||||
|
GROUP BY "userId", day)
|
||||||
|
UNION ALL
|
||||||
|
(SELECT "referrerId" as "userId", 0 as msats_spent, 0 as comments, 0 as posts, 0 as referrals,
|
||||||
|
sum(msats) as msats_stacked,
|
||||||
|
date_trunc('day', timezone('America/Chicago', created_at at time zone 'UTC')) as day
|
||||||
|
FROM "ReferralAct"
|
||||||
|
GROUP BY "userId", day)) u
|
||||||
|
GROUP BY "userId", day;
|
||||||
|
|
||||||
|
CREATE UNIQUE INDEX IF NOT EXISTS user_stats_days_idx ON user_stats_days(day, id);
|
||||||
|
|
||||||
|
-- indices for the other materialized view so we can refresh concurrently
|
||||||
|
CREATE UNIQUE INDEX IF NOT EXISTS reg_growth_days_idx ON reg_growth_days(day);
|
||||||
|
CREATE UNIQUE INDEX IF NOT EXISTS spender_growth_days_idx ON spender_growth_days(day);
|
||||||
|
CREATE UNIQUE INDEX IF NOT EXISTS item_growth_day_idx ON item_growth_days(day);
|
||||||
|
CREATE UNIQUE INDEX IF NOT EXISTS spending_growth_days_idx ON spending_growth_days(day);
|
||||||
|
CREATE UNIQUE INDEX IF NOT EXISTS stackers_growth_days_idx ON stackers_growth_days(day);
|
||||||
|
CREATE UNIQUE INDEX IF NOT EXISTS stacking_growth_days_idx ON stacking_growth_days(day);
|
11
prisma/migrations/20230519194614_more_indices/migration.sql
Normal file
11
prisma/migrations/20230519194614_more_indices/migration.sql
Normal file
@ -0,0 +1,11 @@
|
|||||||
|
-- DropIndex
|
||||||
|
DROP INDEX IF EXISTS "ItemAct.itemId_act_userId_index";
|
||||||
|
|
||||||
|
-- CreateIndex
|
||||||
|
CREATE INDEX IF NOT EXISTS "ItemAct.itemId_userId_act_index" ON "ItemAct"("itemId", "userId", "act");
|
||||||
|
|
||||||
|
-- CreateIndex
|
||||||
|
CREATE INDEX IF NOT EXISTS "ItemAct.userId_created_at_act_index" ON "ItemAct"("userId", "created_at", "act");
|
||||||
|
|
||||||
|
-- CreateIndex
|
||||||
|
CREATE INDEX IF NOT EXISTS "ItemAct.itemId_created_at_act_index" ON "ItemAct"("itemId", "created_at", "act");
|
@ -0,0 +1,2 @@
|
|||||||
|
-- CreateIndex
|
||||||
|
CREATE INDEX "ItemAct.created_at_itemId_act_index" ON "ItemAct"("created_at", "itemId", "act");
|
@ -435,7 +435,14 @@ model ItemAct {
|
|||||||
@@index([userId])
|
@@index([userId])
|
||||||
@@index([act])
|
@@index([act])
|
||||||
@@index([createdAt])
|
@@index([createdAt])
|
||||||
@@index([itemId, act, userId])
|
// for getting a user's spending on an item, eg meSats
|
||||||
|
@@index([itemId, userId, act])
|
||||||
|
// for getting a user's spending over time, eg amount spent in a week
|
||||||
|
@@index([userId, createdAt, act])
|
||||||
|
// for checking if an item has been tipped recently, where the item number is small
|
||||||
|
@@index([itemId, createdAt, act])
|
||||||
|
// for checking if an item has been tipped recently, where the recent acts are small
|
||||||
|
@@index([createdAt, itemId, act])
|
||||||
}
|
}
|
||||||
|
|
||||||
model Mention {
|
model Mention {
|
||||||
|
@ -1,13 +1,16 @@
|
|||||||
|
|
||||||
|
// this is intended to be run everyday after midnight CT
|
||||||
function views ({ models }) {
|
function views ({ models }) {
|
||||||
return async function () {
|
return async function () {
|
||||||
console.log('refreshing views')
|
console.log('refreshing stats views')
|
||||||
|
|
||||||
for (const view of ['reg_growth_days', 'spender_growth_days', 'item_growth_days',
|
for (const view of ['reg_growth_days', 'spender_growth_days', 'item_growth_days',
|
||||||
'spending_growth_days', 'stackers_growth_days', 'stacking_growth_days']) {
|
'spending_growth_days', 'stackers_growth_days', 'stacking_growth_days',
|
||||||
await models.$queryRaw(`REFRESH MATERIALIZED VIEW ${view}`)
|
'user_stats_days']) {
|
||||||
|
await models.$queryRaw(`REFRESH MATERIALIZED VIEW CONCURRENTLY ${view}`)
|
||||||
}
|
}
|
||||||
|
|
||||||
console.log('done refreshing views')
|
console.log('done refreshing stats views')
|
||||||
}
|
}
|
||||||
}
|
}
|
||||||
|
|
||||||
|
Loading…
x
Reference in New Issue
Block a user