improve stat gathering

This commit is contained in:
keyan 2024-01-19 15:19:26 -06:00
parent 0134968fc1
commit eb99fcef9e
7 changed files with 572 additions and 396 deletions

View File

@ -1,22 +1,5 @@
import { timeUnitForRange, whenRange } from '../../lib/time' import { timeUnitForRange, whenRange } from '../../lib/time'
const PLACEHOLDERS_NUM = 616
export function interval (when) {
switch (when) {
case 'week':
return '1 week'
case 'month':
return '1 month'
case 'year':
return '1 year'
case 'forever':
return null
default:
return '1 day'
}
}
export function withClause (range) { export function withClause (range) {
const unit = timeUnitForRange(range) const unit = timeUnitForRange(range)
@ -39,7 +22,28 @@ export function intervalClause (range, table) {
} }
export function viewIntervalClause (range, view) { export function viewIntervalClause (range, view) {
return `"${view}".day >= date_trunc('day', timezone('America/Chicago', $1)) AND "${view}".day <= date_trunc('day', timezone('America/Chicago', $2)) ` const unit = timeUnitForRange(range)
return `"${view}".t >= date_trunc('${unit}', timezone('America/Chicago', $1)) AND date_trunc('${unit}', "${view}".t) <= date_trunc('${unit}', timezone('America/Chicago', $2)) `
}
export function viewGroup (range, view) {
const unit = timeUnitForRange(range)
return `(
(SELECT *
FROM ${view}_days
WHERE ${viewIntervalClause(range, `${view}_days`)})
UNION ALL
(SELECT *
FROM ${view}_hours
WHERE ${viewIntervalClause(range, `${view}_hours`)}
${unit === 'hour' ? '' : `AND "${view}_hours".t >= date_trunc('day', timezone('America/Chicago', now()))`})
UNION ALL
(SELECT * FROM
${view}(
date_trunc('hour', timezone('America/Chicago', now())),
date_trunc('hour', timezone('America/Chicago', now())), '1 hour'::INTERVAL, 'hour')
WHERE "${view}".t >= date_trunc('${unit}', timezone('America/Chicago', $1)))
) u`
} }
export default { export default {
@ -47,251 +51,94 @@ export default {
registrationGrowth: async (parent, { when, from, to }, { models }) => { registrationGrowth: async (parent, { when, from, to }, { models }) => {
const range = whenRange(when, from, to) const range = whenRange(when, from, to)
if (when !== 'day') { return await models.$queryRawUnsafe(`
return await models.$queryRawUnsafe(` SELECT date_trunc('${timeUnitForRange(range)}', t) at time zone 'America/Chicago' as time, json_build_array(
SELECT date_trunc('${timeUnitForRange(range)}', day) as time, json_build_array( json_build_object('name', 'referrals', 'value', sum(referrals)),
json_build_object('name', 'referrals', 'value', sum(referrals)), json_build_object('name', 'organic', 'value', sum(organic))
json_build_object('name', 'organic', 'value', sum(organic))
) AS data
FROM reg_growth_days
WHERE ${viewIntervalClause(range, 'reg_growth_days')}
GROUP BY time
ORDER BY time ASC`, ...range)
}
return await models.$queryRawUnsafe(
`${withClause(range)}
SELECT time, json_build_array(
json_build_object('name', 'referrals', 'value', count("referrerId")),
json_build_object('name', 'organic', 'value', count(users.id) FILTER(WHERE id > ${PLACEHOLDERS_NUM}) - count("referrerId"))
) AS data ) AS data
FROM times FROM ${viewGroup(range, 'reg_growth')}
LEFT JOIN users ON ${intervalClause(range, 'users')} AND time = date_trunc('${timeUnitForRange(range)}', created_at)
GROUP BY time GROUP BY time
ORDER BY time ASC`, ...range) ORDER BY time ASC`, ...range)
}, },
spenderGrowth: async (parent, { when, to, from }, { models }) => { spenderGrowth: async (parent, { when, to, from }, { models }) => {
const range = whenRange(when, from, to) const range = whenRange(when, from, to)
if (when !== 'day') { return await models.$queryRawUnsafe(`
return await models.$queryRawUnsafe(` SELECT date_trunc('${timeUnitForRange(range)}', t) at time zone 'America/Chicago' as time, json_build_array(
SELECT date_trunc('${timeUnitForRange(range)}', day) as time, json_build_array( json_build_object('name', 'any', 'value', COUNT(DISTINCT "userId")),
json_build_object('name', 'any', 'value', floor(avg("any"))), json_build_object('name', 'jobs', 'value', COUNT(DISTINCT "userId") FILTER (WHERE type = 'STREAM')),
json_build_object('name', 'jobs', 'value', floor(avg(jobs))), json_build_object('name', 'boost', 'value', COUNT(DISTINCT "userId") FILTER (WHERE type = 'BOOST')),
json_build_object('name', 'boost', 'value', floor(avg(boost))), json_build_object('name', 'fees', 'value', COUNT(DISTINCT "userId") FILTER (WHERE type = 'FEE')),
json_build_object('name', 'fees', 'value', floor(avg(fees))), json_build_object('name', 'poll', 'value', COUNT(DISTINCT "userId") FILTER (WHERE type = 'POLL')),
json_build_object('name', 'zaps', 'value', floor(avg(tips))), json_build_object('name', 'downzaps', 'value', COUNT(DISTINCT "userId") FILTER (WHERE type = 'DONT_LIKE_THIS')),
json_build_object('name', 'donation', 'value', floor(avg(donations))), json_build_object('name', 'zaps', 'value', COUNT(DISTINCT "userId") FILTER (WHERE type = 'TIP')),
json_build_object('name', 'territories', 'value', floor(avg(territories))) json_build_object('name', 'donation', 'value', COUNT(DISTINCT "userId") FILTER (WHERE type = 'DONATION')),
) AS data json_build_object('name', 'territories', 'value', COUNT(DISTINCT "userId") FILTER (WHERE type = 'TERRITORY'))
FROM spender_growth_days
WHERE ${viewIntervalClause(range, 'spender_growth_days')}
GROUP BY time
ORDER BY time ASC`, ...range)
}
return await models.$queryRawUnsafe(
`${withClause(range)}
SELECT time, json_build_array(
json_build_object('name', 'any', 'value', count(DISTINCT "userId")),
json_build_object('name', 'jobs', 'value', count(DISTINCT "userId") FILTER (WHERE act = 'STREAM')),
json_build_object('name', 'boost', 'value', count(DISTINCT "userId") FILTER (WHERE act = 'BOOST')),
json_build_object('name', 'fees', 'value', count(DISTINCT "userId") FILTER (WHERE act = 'FEE')),
json_build_object('name', 'zaps', 'value', count(DISTINCT "userId") FILTER (WHERE act = 'TIP')),
json_build_object('name', 'donation', 'value', count(DISTINCT "userId") FILTER (WHERE act = 'DONATION')),
json_build_object('name', 'territories', 'value', count(DISTINCT "userId") FILTER (WHERE act = 'TERRITORY'))
) AS data ) AS data
FROM times FROM ${viewGroup(range, 'spender_growth')}
LEFT JOIN
((SELECT "ItemAct".created_at, "userId", act::text as act
FROM "ItemAct"
WHERE ${intervalClause(range, 'ItemAct')})
UNION ALL
(SELECT created_at, "userId", 'DONATION' as act
FROM "Donation"
WHERE ${intervalClause(range, 'Donation')})
UNION ALL
(SELECT created_at, "userId", 'TERRITORY' as act
FROM "SubAct"
WHERE type = 'BILLING' AND ${intervalClause(range, 'SubAct')})
) u ON time = date_trunc('${timeUnitForRange(range)}', u.created_at)
GROUP BY time GROUP BY time
ORDER BY time ASC`, ...range) ORDER BY time ASC`, ...range)
}, },
itemGrowth: async (parent, { when, to, from }, { models }) => { itemGrowth: async (parent, { when, to, from }, { models }) => {
const range = whenRange(when, from, to) const range = whenRange(when, from, to)
if (when !== 'day') { return await models.$queryRawUnsafe(`
return await models.$queryRawUnsafe(` SELECT date_trunc('${timeUnitForRange(range)}', t) at time zone 'America/Chicago' as time, json_build_array(
SELECT date_trunc('${timeUnitForRange(range)}', day) as time, json_build_array( json_build_object('name', 'posts', 'value', sum(posts)),
json_build_object('name', 'posts', 'value', sum(posts)), json_build_object('name', 'comments', 'value', sum(comments)),
json_build_object('name', 'comments', 'value', sum(comments)), json_build_object('name', 'jobs', 'value', sum(jobs)),
json_build_object('name', 'jobs', 'value', sum(jobs)), json_build_object('name', 'zaps', 'value', sum(zaps)),
json_build_object('name', 'comments/posts', 'value', ROUND(sum(comments)/GREATEST(sum(posts), 1), 2)) json_build_object('name', 'territories', 'value', sum(territories)),
) AS data json_build_object('name', 'comments/posts', 'value', ROUND(sum(comments)/GREATEST(sum(posts), 1), 2))
FROM item_growth_days
WHERE ${viewIntervalClause(range, 'item_growth_days')}
GROUP BY time
ORDER BY time ASC`, ...range)
}
return await models.$queryRawUnsafe(
`${withClause(range)}
SELECT time, json_build_array(
json_build_object('name', 'comments', 'value', count("parentId")),
json_build_object('name', 'jobs', 'value', count("subName") FILTER (WHERE "subName" = 'jobs')),
json_build_object('name', 'posts', 'value', count("Item".id)-count("parentId")-(count("subName") FILTER (WHERE "subName" = 'jobs'))),
json_build_object('name', 'comments/posts', 'value', ROUND(count("parentId")/GREATEST(count("Item".id)-count("parentId"), 1), 2))
) AS data ) AS data
FROM times FROM ${viewGroup(range, 'item_growth')}
LEFT JOIN "Item" ON ${intervalClause(range, 'Item')} AND time = date_trunc('${timeUnitForRange(range)}', created_at)
GROUP BY time GROUP BY time
ORDER BY time ASC`, ...range) ORDER BY time ASC`, ...range)
}, },
spendingGrowth: async (parent, { when, to, from }, { models }) => { spendingGrowth: async (parent, { when, to, from }, { models }) => {
const range = whenRange(when, from, to) const range = whenRange(when, from, to)
if (when !== 'day') { return await models.$queryRawUnsafe(`
return await models.$queryRawUnsafe(` SELECT date_trunc('${timeUnitForRange(range)}', t) at time zone 'America/Chicago' as time, json_build_array(
SELECT date_trunc('${timeUnitForRange(range)}', day) as time, json_build_array( json_build_object('name', 'jobs', 'value', sum(jobs)),
json_build_object('name', 'jobs', 'value', sum(jobs)), json_build_object('name', 'boost', 'value', sum(boost)),
json_build_object('name', 'boost', 'value', sum(boost)), json_build_object('name', 'fees', 'value', sum(fees)),
json_build_object('name', 'fees', 'value', sum(fees)), json_build_object('name', 'zaps', 'value', sum(tips)),
json_build_object('name', 'zaps', 'value', sum(tips)), json_build_object('name', 'donations', 'value', sum(donations)),
json_build_object('name', 'donations', 'value', sum(donations)), json_build_object('name', 'territories', 'value', sum(territories))
json_build_object('name', 'territories', 'value', sum(territories))
) AS data
FROM spending_growth_days
WHERE ${viewIntervalClause(range, 'spending_growth_days')}
GROUP BY time
ORDER BY time ASC`, ...range)
}
return await models.$queryRawUnsafe(
`${withClause(range)}
SELECT time, json_build_array(
json_build_object('name', 'jobs', 'value', coalesce(floor(sum(CASE WHEN act = 'STREAM' THEN msats ELSE 0 END)/1000),0)),
json_build_object('name', 'boost', 'value', coalesce(floor(sum(CASE WHEN act = 'BOOST' THEN msats ELSE 0 END)/1000),0)),
json_build_object('name', 'fees', 'value', coalesce(floor(sum(CASE WHEN act NOT IN ('BOOST', 'TIP', 'STREAM', 'DONATION', 'REVENUE') THEN msats ELSE 0 END)/1000),0)),
json_build_object('name', 'zaps', 'value', coalesce(floor(sum(CASE WHEN act = 'TIP' THEN msats ELSE 0 END)/1000),0)),
json_build_object('name', 'donations', 'value', coalesce(floor(sum(CASE WHEN act = 'DONATION' THEN msats ELSE 0 END)/1000),0)),
json_build_object('name', 'territories', 'value', coalesce(floor(sum(CASE WHEN act = 'REVENUE' THEN msats ELSE 0 END)/1000),0))
) AS data ) AS data
FROM times FROM ${viewGroup(range, 'spending_growth')}
LEFT JOIN
((SELECT "ItemAct".created_at, msats, act::text as act
FROM "ItemAct"
WHERE ${intervalClause(range, 'ItemAct')})
UNION ALL
(SELECT created_at, sats * 1000 as msats, 'DONATION' as act
FROM "Donation"
WHERE ${intervalClause(range, 'Donation')})
UNION ALL
(SELECT created_at, msats, 'REVENUE' as act
FROM "SubAct"
WHERE type = 'BILLING' AND ${intervalClause(range, 'SubAct')})
) u ON time = date_trunc('${timeUnitForRange(range)}', u.created_at)
GROUP BY time GROUP BY time
ORDER BY time ASC`, ...range) ORDER BY time ASC`, ...range)
}, },
stackerGrowth: async (parent, { when, to, from }, { models }) => { stackerGrowth: async (parent, { when, to, from }, { models }) => {
const range = whenRange(when, from, to) const range = whenRange(when, from, to)
if (when !== 'day') { return await models.$queryRawUnsafe(`
return await models.$queryRawUnsafe(` SELECT date_trunc('${timeUnitForRange(range)}', t) at time zone 'America/Chicago' as time, json_build_array(
SELECT date_trunc('${timeUnitForRange(range)}', day) as time, json_build_array( json_build_object('name', 'any', 'value', COUNT(DISTINCT "userId")),
json_build_object('name', 'any', 'value', floor(avg("any"))), json_build_object('name', 'posts', 'value', COUNT(DISTINCT "userId") FILTER (WHERE type = 'POST')),
json_build_object('name', 'posts', 'value', floor(avg(posts))), json_build_object('name', 'comments', 'value', COUNT(DISTINCT "userId") FILTER (WHERE type = 'COMMENT')),
json_build_object('name', 'comments', 'value', floor(floor(avg(comments)))), json_build_object('name', 'rewards', 'value', COUNT(DISTINCT "userId") FILTER (WHERE type = 'EARN')),
json_build_object('name', 'rewards', 'value', floor(avg(rewards))), json_build_object('name', 'referrals', 'value', COUNT(DISTINCT "userId") FILTER (WHERE type = 'REFERRAL')),
json_build_object('name', 'referrals', 'value', floor(avg(referrals))), json_build_object('name', 'territories', 'value', COUNT(DISTINCT "userId") FILTER (WHERE type = 'REVENUE'))
json_build_object('name', 'territories', 'value', floor(avg(territories)))
) AS data
FROM stackers_growth_days
WHERE ${viewIntervalClause(range, 'stackers_growth_days')}
GROUP BY time
ORDER BY time ASC`, ...range)
}
return await models.$queryRawUnsafe(
`${withClause(range)}
SELECT time, json_build_array(
json_build_object('name', 'any', 'value', count(distinct user_id)),
json_build_object('name', 'posts', 'value', count(distinct user_id) FILTER (WHERE type = 'POST')),
json_build_object('name', 'comments', 'value', count(distinct user_id) FILTER (WHERE type = 'COMMENT')),
json_build_object('name', 'rewards', 'value', count(distinct user_id) FILTER (WHERE type = 'EARN')),
json_build_object('name', 'referrals', 'value', count(distinct user_id) FILTER (WHERE type = 'REFERRAL')),
json_build_object('name', 'territories', 'value', count(distinct user_id) FILTER (WHERE type = 'REVENUE'))
) AS data ) AS data
FROM times FROM ${viewGroup(range, 'stackers_growth')}
LEFT JOIN
((SELECT "ItemAct".created_at, "Item"."userId" as user_id, CASE WHEN "Item"."parentId" IS NULL THEN 'POST' ELSE 'COMMENT' END as type
FROM "ItemAct"
JOIN "Item" on "ItemAct"."itemId" = "Item".id
WHERE ${intervalClause(range, 'ItemAct')} AND "ItemAct".act = 'TIP')
UNION ALL
(SELECT created_at, "userId" as user_id, 'EARN' as type
FROM "Earn"
WHERE ${intervalClause(range, 'Earn')})
UNION ALL
(SELECT created_at, "userId" as user_id, 'REVENUE' as type
FROM "SubAct"
WHERE type = 'REVENUE' AND ${intervalClause(range, 'SubAct')})
UNION ALL
(SELECT created_at, "referrerId" as user_id, 'REFERRAL' as type
FROM "ReferralAct"
WHERE ${intervalClause(range, 'ReferralAct')})) u ON time = date_trunc('${timeUnitForRange(range)}', u.created_at)
GROUP BY time GROUP BY time
ORDER BY time ASC`, ...range) ORDER BY time ASC`, ...range)
}, },
stackingGrowth: async (parent, { when, to, from }, { models }) => { stackingGrowth: async (parent, { when, to, from }, { models }) => {
const range = whenRange(when, from, to) const range = whenRange(when, from, to)
if (when !== 'day') { return await models.$queryRawUnsafe(`
return await models.$queryRawUnsafe(` SELECT date_trunc('${timeUnitForRange(range)}', t) at time zone 'America/Chicago' as time, json_build_array(
SELECT date_trunc('${timeUnitForRange(range)}', day) as time, json_build_array( json_build_object('name', 'rewards', 'value', sum(rewards)),
json_build_object('name', 'rewards', 'value', sum(rewards)), json_build_object('name', 'posts', 'value', sum(posts)),
json_build_object('name', 'posts', 'value', sum(posts)), json_build_object('name', 'comments', 'value', sum(comments)),
json_build_object('name', 'comments', 'value', sum(comments)), json_build_object('name', 'referrals', 'value', sum(referrals)),
json_build_object('name', 'referrals', 'value', sum(referrals)), json_build_object('name', 'territories', 'value', sum(territories))
json_build_object('name', 'territories', 'value', sum(territories))
) AS data
FROM stacking_growth_days
WHERE ${viewIntervalClause(range, 'stacking_growth_days')}
GROUP BY time
ORDER BY time ASC`, ...range)
}
return await models.$queryRawUnsafe(
`${withClause(range)}
SELECT time, json_build_array(
json_build_object('name', 'rewards', 'value', coalesce(floor(sum(airdrop)/1000),0)),
json_build_object('name', 'posts', 'value', coalesce(floor(sum(post)/1000),0)),
json_build_object('name', 'comments', 'value', coalesce(floor(sum(comment)/1000),0)),
json_build_object('name', 'referrals', 'value', coalesce(floor(sum(referral)/1000),0)),
json_build_object('name', 'territories', 'value', coalesce(floor(sum(revenue)/1000),0))
) AS data ) AS data
FROM times FROM ${viewGroup(range, 'stacking_growth')}
LEFT JOIN
((SELECT "ItemAct".created_at, 0 as airdrop,
CASE WHEN "Item"."parentId" IS NULL THEN 0 ELSE "ItemAct".msats END as comment,
CASE WHEN "Item"."parentId" IS NULL THEN "ItemAct".msats ELSE 0 END as post,
0 as referral, 0 as revenue
FROM "ItemAct"
JOIN "Item" on "ItemAct"."itemId" = "Item".id
WHERE ${intervalClause(range, 'ItemAct')} AND "ItemAct".act = 'TIP')
UNION ALL
(SELECT created_at, 0 as airdrop, 0 as post, 0 as comment, msats as referral, 0 as revenue
FROM "ReferralAct"
WHERE ${intervalClause(range, 'ReferralAct')})
UNION ALL
(SELECT created_at, 0 as airdrop, 0 as post, 0 as comment, 0 as referral, msats as revenue
FROM "SubAct"
WHERE type = 'REVENUE' AND ${intervalClause(range, 'SubAct')})
UNION ALL
(SELECT created_at, msats as airdrop, 0 as post, 0 as comment, 0 as referral, 0 as revenue
FROM "Earn"
WHERE ${intervalClause(range, 'Earn')})) u ON time = date_trunc('${timeUnitForRange(range)}', u.created_at)
GROUP BY time GROUP BY time
ORDER BY time ASC`, ...range) ORDER BY time ASC`, ...range)
} }

View File

@ -6,7 +6,7 @@ import { msatsToSats } from '../../lib/format'
import { bioSchema, emailSchema, lnAddrAutowithdrawSchema, settingsSchema, ssValidate, userSchema } from '../../lib/validate' import { bioSchema, emailSchema, lnAddrAutowithdrawSchema, settingsSchema, ssValidate, userSchema } from '../../lib/validate'
import { getItem, updateItem, filterClause, createItem, whereClause, muteClause } from './item' import { getItem, updateItem, filterClause, createItem, whereClause, muteClause } from './item'
import { ANON_USER_ID, DELETE_USER_ID, RESERVED_MAX_USER_ID } from '../../lib/constants' import { ANON_USER_ID, DELETE_USER_ID, RESERVED_MAX_USER_ID } from '../../lib/constants'
import { viewIntervalClause, intervalClause } from './growth' import { viewGroup } from './growth'
import { whenRange } from '../../lib/time' import { whenRange } from '../../lib/time'
const contributors = new Set() const contributors = new Set()
@ -80,6 +80,8 @@ export default {
}, },
topCowboys: async (parent, { cursor }, { models, me }) => { topCowboys: async (parent, { cursor }, { models, me }) => {
const decodedCursor = decodeCursor(cursor) const decodedCursor = decodeCursor(cursor)
const range = whenRange('forever')
const users = await models.$queryRawUnsafe(` const users = await models.$queryRawUnsafe(`
SELECT users.*, SELECT users.*,
coalesce(floor(sum(msats_spent)/1000),0) as spent, coalesce(floor(sum(msats_spent)/1000),0) as spent,
@ -87,13 +89,13 @@ export default {
coalesce(sum(comments),0) as ncomments, coalesce(sum(comments),0) as ncomments,
coalesce(sum(referrals),0) as referrals, coalesce(sum(referrals),0) as referrals,
coalesce(floor(sum(msats_stacked)/1000),0) as stacked coalesce(floor(sum(msats_stacked)/1000),0) as stacked
FROM users FROM ${viewGroup(range, 'user_stats')}
LEFT JOIN user_stats_days on users.id = user_stats_days.id JOIN users on users.id = u.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 GROUP BY users.id
ORDER BY streak DESC, created_at ASC ORDER BY streak DESC, created_at ASC
OFFSET $1 OFFSET $3
LIMIT ${LIMIT}`, decodedCursor.offset) LIMIT ${LIMIT}`, ...range, decodedCursor.offset)
return { return {
cursor: users.length === LIMIT ? nextCursorEncoded(decodedCursor) : null, cursor: users.length === LIMIT ? nextCursorEncoded(decodedCursor) : null,
users users
@ -127,123 +129,30 @@ export default {
topUsers: async (parent, { cursor, when, by, from, to, limit = LIMIT }, { models, me }) => { topUsers: async (parent, { cursor, when, by, from, to, limit = LIMIT }, { models, me }) => {
const decodedCursor = decodeCursor(cursor) const decodedCursor = decodeCursor(cursor)
const range = whenRange(when, from, to || decodeCursor.time) const range = whenRange(when, from, to || decodeCursor.time)
let users
if (when !== 'day') { let column
let column switch (by) {
switch (by) { case 'spent': column = 'spent'; break
case 'spent': column = 'spent'; break case 'posts': column = 'nposts'; break
case 'posts': column = 'nposts'; break case 'comments': column = 'ncomments'; break
case 'comments': column = 'ncomments'; break case 'referrals': column = 'referrals'; break
case 'referrals': column = 'referrals'; break default: column = 'stacked'; break
default: column = 'stacked'; break
}
users = await models.$queryRawUnsafe(`
WITH u AS (
SELECT users.*, floor(sum(msats_spent)/1000) as spent,
sum(posts) as nposts, 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"
AND ${viewIntervalClause(range, 'user_stats_days')}
GROUP BY users.id
ORDER BY ${column} DESC NULLS LAST, users.created_at DESC
)
SELECT * FROM u WHERE ${column} > 0
OFFSET $3
LIMIT $4`, ...range, decodedCursor.offset, limit)
return {
cursor: users.length === limit ? nextCursorEncoded(decodedCursor, limit) : null,
users
}
} }
if (by === 'spent') { const users = await models.$queryRawUnsafe(`
users = await models.$queryRawUnsafe(` SELECT users.*,
SELECT users.*, sum(sats_spent) as spent COALESCE(floor(sum(msats_spent)/1000), 0) as spent,
FROM COALESCE(sum(posts), 0) as nposts,
((SELECT "userId", floor(sum("ItemAct".msats)/1000) as sats_spent COALESCE(sum(comments), 0) as ncomments,
FROM "ItemAct" COALESCE(sum(referrals), 0) as referrals,
WHERE ${intervalClause(range, 'ItemAct')} COALESCE(floor(sum(msats_stacked)/1000), 0) as stacked
GROUP BY "userId") FROM ${viewGroup(range, 'user_stats')}
UNION ALL JOIN users on users.id = u.id
(SELECT "userId", sats as sats_spent WHERE NOT users."hideFromTopUsers"
FROM "Donation"
WHERE ${intervalClause(range, 'Donation')})) spending
JOIN users on spending."userId" = users.id
AND NOT users."hideFromTopUsers"
GROUP BY users.id, users.name
ORDER BY spent DESC NULLS LAST, users.created_at DESC
OFFSET $3
LIMIT $4`, ...range, decodedCursor.offset, limit)
} else if (by === 'posts') {
users = await models.$queryRawUnsafe(`
SELECT users.*, count(*)::INTEGER as nposts
FROM users
JOIN "Item" on "Item"."userId" = users.id
WHERE "Item"."parentId" IS NULL
AND NOT users."hideFromTopUsers"
AND ${intervalClause(range, 'Item')}
GROUP BY users.id GROUP BY users.id
ORDER BY nposts DESC NULLS LAST, users.created_at DESC ORDER BY ${column} DESC NULLS LAST, users.created_at ASC
OFFSET $3 OFFSET $3
LIMIT $4`, ...range, decodedCursor.offset, limit) LIMIT $4`, ...range, decodedCursor.offset, limit)
} else if (by === 'comments') {
users = await models.$queryRawUnsafe(`
SELECT users.*, count(*)::INTEGER as ncomments
FROM users
JOIN "Item" on "Item"."userId" = users.id
WHERE "Item"."parentId" IS NOT NULL
AND NOT users."hideFromTopUsers"
AND ${intervalClause(range, 'Item')}
GROUP BY users.id
ORDER BY ncomments DESC NULLS LAST, users.created_at DESC
OFFSET $3
LIMIT $4`, ...range, decodedCursor.offset, limit)
} else if (by === 'referrals') {
users = await models.$queryRawUnsafe(`
SELECT users.*, count(*)::INTEGER as referrals
FROM users
JOIN "users" referree on users.id = referree."referrerId"
AND NOT users."hideFromTopUsers"
AND ${intervalClause(range, 'referree')}
GROUP BY users.id
ORDER BY referrals DESC NULLS LAST, users.created_at DESC
OFFSET $3
LIMIT $4`, ...range, decodedCursor.offset, limit)
} else {
users = await models.$queryRawUnsafe(`
SELECT u.id, u.name, u.streak, u."photoId", u."hideCowboyHat", floor(sum(amount)/1000) as stacked
FROM
((SELECT users.*, "ItemAct".msats as amount
FROM "ItemAct"
JOIN "Item" on "ItemAct"."itemId" = "Item".id
JOIN users on "Item"."userId" = users.id
WHERE act <> 'BOOST' AND "ItemAct"."userId" <> users.id
AND NOT users."hideFromTopUsers"
AND ${intervalClause(range, 'ItemAct')})
UNION ALL
(SELECT users.*, "Earn".msats as amount
FROM "Earn"
JOIN users on users.id = "Earn"."userId"
WHERE "Earn".msats > 0
AND ${intervalClause(range, 'Earn')}
AND NOT users."hideFromTopUsers")
UNION ALL
(SELECT users.*, "ReferralAct".msats as amount
FROM "ReferralAct"
JOIN users on users.id = "ReferralAct"."referrerId"
WHERE "ReferralAct".msats > 0
AND ${intervalClause(range, 'ReferralAct')}
AND NOT users."hideFromTopUsers")) u
GROUP BY u.id, u.name, u.created_at, u."photoId", u.streak, u."hideCowboyHat"
ORDER BY stacked DESC NULLS LAST, created_at DESC
OFFSET $3
LIMIT $4`, ...range, decodedCursor.offset, limit)
}
return { return {
cursor: users.length === limit ? nextCursorEncoded(decodedCursor, limit) : null, cursor: users.length === limit ? nextCursorEncoded(decodedCursor, limit) : null,
@ -887,30 +796,14 @@ export default {
if (!when || when === 'forever') { if (!when || when === 'forever') {
// forever // forever
return (user.stackedMsats && msatsToSats(user.stackedMsats)) || 0 return (user.stackedMsats && msatsToSats(user.stackedMsats)) || 0
} else if (when === 'day') {
const range = whenRange(when, from, to)
const [{ stacked }] = await models.$queryRawUnsafe(`
SELECT sum(amount) as stacked
FROM
((SELECT coalesce(sum("ItemAct".msats),0) as amount
FROM "ItemAct"
JOIN "Item" on "ItemAct"."itemId" = "Item".id
WHERE act = 'TIP' AND "ItemAct"."userId" <> $3 AND "Item"."userId" = $3
AND ${intervalClause(range, 'ItemAct')})
UNION ALL
(SELECT coalesce(sum("ReferralAct".msats),0) as amount
FROM "ReferralAct"
WHERE "ReferralAct".msats > 0 AND "ReferralAct"."referrerId" = $3
AND ${intervalClause(range, 'ReferralAct')})
UNION ALL
(SELECT coalesce(sum("Earn".msats), 0) as amount
FROM "Earn"
WHERE "Earn".msats > 0 AND "Earn"."userId" = $3
AND ${intervalClause(range, 'Earn')})) u`, ...range, Number(user.id))
return (stacked && msatsToSats(stacked)) || 0
} }
return 0 const range = whenRange(when, from, to)
const [{ stacked }] = await models.$queryRawUnsafe(`
SELECT sum(msats_stacked) as stacked
FROM ${viewGroup(range, 'user_stats')}
WHERE id = $3`, ...range, Number(user.id))
return (stacked && msatsToSats(stacked)) || 0
}, },
spent: async (user, { when, from, to }, { models, me }) => { spent: async (user, { when, from, to }, { models, me }) => {
if ((!me || me.id !== user.id) && user.hideFromTopUsers) { if ((!me || me.id !== user.id) && user.hideFromTopUsers) {
@ -921,21 +814,13 @@ export default {
return user.spent return user.spent
} }
const [gte, lte] = whenRange(when, from, to) const range = whenRange(when, from, to)
const { _sum: { msats } } = await models.itemAct.aggregate({ const [{ spent }] = await models.$queryRawUnsafe(`
_sum: { SELECT sum(msats_spent) as spent
msats: true FROM ${viewGroup(range, 'user_stats')}
}, WHERE id = $3`, ...range, Number(user.id))
where: {
userId: user.id,
createdAt: {
gte,
lte
}
}
})
return (msats && msatsToSats(msats)) || 0 return (spent && msatsToSats(spent)) || 0
}, },
referrals: async (user, { when, from, to }, { models, me }) => { referrals: async (user, { when, from, to }, { models, me }) => {
if ((!me || me.id !== user.id) && user.hideFromTopUsers) { if ((!me || me.id !== user.id) && user.hideFromTopUsers) {

View File

@ -70,9 +70,14 @@ const COLORS = [
'var(--bs-success)', 'var(--bs-success)',
'var(--bs-boost)', 'var(--bs-boost)',
'var(--theme-grey)', 'var(--theme-grey)',
'var(--bs-danger)' 'var(--bs-danger)',
'var(--bs-code-color)'
] ]
function getColor (i) {
return COLORS[i % COLORS.length]
}
export function WhenAreaChart ({ data }) { export function WhenAreaChart ({ data }) {
const router = useRouter() const router = useRouter()
if (!data || data.length === 0) { if (!data || data.length === 0) {
@ -104,7 +109,7 @@ export function WhenAreaChart ({ data }) {
<Tooltip labelFormatter={labelFormatter(when, from, to)} contentStyle={{ color: 'var(--bs-body-color)', backgroundColor: 'var(--bs-body-bg)' }} /> <Tooltip labelFormatter={labelFormatter(when, from, to)} contentStyle={{ color: 'var(--bs-body-color)', backgroundColor: 'var(--bs-body-bg)' }} />
<Legend /> <Legend />
{Object.keys(data[0]).filter(v => v !== 'time' && v !== '__typename').map((v, i) => {Object.keys(data[0]).filter(v => v !== 'time' && v !== '__typename').map((v, i) =>
<Area key={v} type='monotone' dataKey={v} name={v} stackId='1' stroke={COLORS[i]} fill={COLORS[i]} />)} <Area key={v} type='monotone' dataKey={v} name={v} stackId='1' stroke={getColor(i)} fill={getColor(i)} />)}
</AreaChart> </AreaChart>
</ResponsiveContainer> </ResponsiveContainer>
) )
@ -141,7 +146,7 @@ export function WhenLineChart ({ data }) {
<Tooltip labelFormatter={labelFormatter(when, from, to)} contentStyle={{ color: 'var(--bs-body-color)', backgroundColor: 'var(--bs-body-bg)' }} /> <Tooltip labelFormatter={labelFormatter(when, from, to)} contentStyle={{ color: 'var(--bs-body-color)', backgroundColor: 'var(--bs-body-bg)' }} />
<Legend /> <Legend />
{Object.keys(data[0]).filter(v => v !== 'time' && v !== '__typename').map((v, i) => {Object.keys(data[0]).filter(v => v !== 'time' && v !== '__typename').map((v, i) =>
<Line key={v} type='monotone' dataKey={v} name={v} stroke={COLORS[i]} fill={COLORS[i]} />)} <Line key={v} type='monotone' dataKey={v} name={v} stroke={getColor(i)} fill={getColor(i)} />)}
</LineChart> </LineChart>
</ResponsiveContainer> </ResponsiveContainer>
) )
@ -184,11 +189,11 @@ export function WhenComposedChart ({
<Tooltip labelFormatter={labelFormatter(when, from, to)} contentStyle={{ color: 'var(--bs-body-color)', backgroundColor: 'var(--bs-body-bg)' }} /> <Tooltip labelFormatter={labelFormatter(when, from, to)} contentStyle={{ color: 'var(--bs-body-color)', backgroundColor: 'var(--bs-body-bg)' }} />
<Legend /> <Legend />
{barNames?.map((v, i) => {barNames?.map((v, i) =>
<Bar yAxisId={barAxis} key={v} type='monotone' dataKey={v} name={v} stroke='var(--bs-info)' fill='var(--bs-info)' />)} <Bar yAxisId={barAxis} key={v} type='monotone' dataKey={v} name={v} stroke={getColor(i)} fill={getColor(i)} />)}
{areaNames?.map((v, i) => {areaNames?.map((v, i) =>
<Area yAxisId={areaAxis} key={v} type='monotone' dataKey={v} name={v} stackId='1' stroke={COLORS[i]} fill={COLORS[i]} />)} <Area yAxisId={areaAxis} key={v} type='monotone' dataKey={v} name={v} stackId='1' stroke={getColor(barNames.length + i)} fill={getColor(barNames.length + i)} />)}
{lineNames?.map((v, i) => {lineNames?.map((v, i) =>
<Line yAxisId={lineAxis} key={v} type='monotone' dataKey={v} name={v} stackId='1' stroke={COLORS[areaNames.length + i]} />)} <Line yAxisId={lineAxis} key={v} type='monotone' dataKey={v} name={v} stackId='1' stroke={getColor(barNames.length + areaNames.length + i)} />)}
</ComposedChart> </ComposedChart>
</ResponsiveContainer> </ResponsiveContainer>
) )
@ -214,7 +219,7 @@ export function GrowthPieChart ({ data }) {
> >
{ {
data.map((entry, index) => ( data.map((entry, index) => (
<Cell key={`cell-${index}`} fill={COLORS[index]} /> <Cell key={`cell-${index}`} fill={getColor(index)} />
)) ))
} }
</Pie> </Pie>

View File

@ -70,7 +70,6 @@ export const getServerSideProps = getGetServerSideProps({ query: GROWTH_QUERY })
export default function Growth ({ ssrData }) { export default function Growth ({ ssrData }) {
const router = useRouter() const router = useRouter()
const { when, from, to } = router.query const { when, from, to } = router.query
const avg = ['year', 'forever'].includes(when) ? 'avg daily ' : ''
const { data } = useQuery(GROWTH_QUERY, { variables: { when, from, to } }) const { data } = useQuery(GROWTH_QUERY, { variables: { when, from, to } })
if (!data && !ssrData) return <PageLoading /> if (!data && !ssrData) return <PageLoading />
@ -82,7 +81,7 @@ export default function Growth ({ ssrData }) {
<UsageHeader /> <UsageHeader />
<Row> <Row>
<Col className='mt-3'> <Col className='mt-3'>
<div className='text-center text-muted fw-bold'>{avg}stackers</div> <div className='text-center text-muted fw-bold'>stackers</div>
<WhenLineChart data={stackerGrowth} /> <WhenLineChart data={stackerGrowth} />
</Col> </Col>
<Col className='mt-3'> <Col className='mt-3'>
@ -92,7 +91,7 @@ export default function Growth ({ ssrData }) {
</Row> </Row>
<Row> <Row>
<Col className='mt-3'> <Col className='mt-3'>
<div className='text-center text-muted fw-bold'>{avg}spenders</div> <div className='text-center text-muted fw-bold'>spenders</div>
<WhenLineChart data={spenderGrowth} /> <WhenLineChart data={spenderGrowth} />
</Col> </Col>
<Col className='mt-3'> <Col className='mt-3'>
@ -107,7 +106,7 @@ export default function Growth ({ ssrData }) {
</Col> </Col>
<Col className='mt-3'> <Col className='mt-3'>
<div className='text-center text-muted fw-bold'>items</div> <div className='text-center text-muted fw-bold'>items</div>
<WhenComposedChart data={itemGrowth} areaNames={['posts', 'comments', 'jobs']} areaAxis='left' lineNames={['comments/posts']} lineAxis='right' /> <WhenComposedChart data={itemGrowth} areaNames={['posts', 'comments', 'jobs']} areaAxis='left' lineNames={['comments/posts', 'territories']} lineAxis='right' barNames={['zaps']} />
</Col> </Col>
</Row> </Row>
</Layout> </Layout>

View File

@ -0,0 +1,439 @@
-- all hours for the last day
CREATE OR REPLACE VIEW last_24_hours AS
SELECT date_trunc('hour', timezone('America/Chicago', now() - interval '24 hours')) as min,
date_trunc('hour', timezone('America/Chicago', now() - interval '1 hour')) as max;
-- all days since launch
CREATE OR REPLACE VIEW all_days AS
SELECT date_trunc('day', timezone('America/Chicago', '2021-06-01')) as min,
date_trunc('day', timezone('America/Chicago', now() - interval '1 day')) as max;
CREATE OR REPLACE VIEW all_months AS
SELECT date_trunc('month', timezone('America/Chicago', '2021-06-01')) as min,
date_trunc('month', timezone('America/Chicago', now() - interval '1 month')) as max;
-- get registrations
CREATE OR REPLACE FUNCTION reg_growth(min TIMESTAMP(3), max TIMESTAMP(3), ival INTERVAL, date_part TEXT)
RETURNS TABLE (t TIMESTAMP(3), referrals BIGINT, organic BIGINT)
LANGUAGE plpgsql
AS $$
DECLARE
min_utc TIMESTAMP(3) := timezone('utc', min AT TIME ZONE 'America/Chicago');
BEGIN
RETURN QUERY
SELECT period.t, count("referrerId") as referrals,
count(users.id) FILTER(WHERE id > 616) - count("inviteId") as organic
FROM generate_series(min, max, ival) period(t)
LEFT JOIN users ON period.t = date_trunc(date_part, timezone('America/Chicago', created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago'))
GROUP BY period.t
ORDER BY period.t ASC;
END;
$$;
DROP MATERIALIZED VIEW IF EXISTS reg_growth_hours;
CREATE MATERIALIZED VIEW IF NOT EXISTS reg_growth_hours AS
SELECT (reg_growth(min, max, '1 hour'::INTERVAL, 'hour')).* FROM last_24_hours;
DROP MATERIALIZED VIEW IF EXISTS reg_growth_days;
CREATE MATERIALIZED VIEW IF NOT EXISTS reg_growth_days AS
SELECT (reg_growth(min, max, '1 day'::INTERVAL, 'day')).* FROM all_days;
DROP MATERIALIZED VIEW IF EXISTS reg_growth_months;
CREATE MATERIALIZED VIEW IF NOT EXISTS reg_growth_months AS
SELECT (reg_growth(min, max, '1 month'::INTERVAL, 'month')).* FROM all_months;
-- get spenders
CREATE OR REPLACE FUNCTION spender_growth(min TIMESTAMP(3), max TIMESTAMP(3), ival INTERVAL, date_part TEXT)
RETURNS TABLE (t TIMESTAMP(3), "userId" INT, type TEXT)
LANGUAGE plpgsql
AS $$
DECLARE
min_utc TIMESTAMP(3) := timezone('utc', min AT TIME ZONE 'America/Chicago');
BEGIN
RETURN QUERY
SELECT period.t, u."userId", u.type
FROM generate_series(min, max, ival) period(t)
LEFT JOIN
((SELECT "ItemAct".created_at, "ItemAct"."userId", act::text as type
FROM "ItemAct"
WHERE created_at >= min_utc)
UNION ALL
(SELECT created_at, "Donation"."userId", 'DONATION' as type
FROM "Donation"
WHERE created_at >= min_utc)
UNION ALL
(SELECT created_at, "SubAct"."userId", 'TERRITORY' as type
FROM "SubAct"
WHERE "SubAct".type = 'BILLING'
AND created_at >= min_utc)
) u ON period.t = date_trunc(date_part, u.created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago')
GROUP BY period.t, u."userId", u.type
ORDER BY period.t ASC;
END;
$$;
DROP MATERIALIZED VIEW IF EXISTS spender_growth_hours;
CREATE MATERIALIZED VIEW IF NOT EXISTS spender_growth_hours AS
SELECT (spender_growth(min, max, '1 hour'::INTERVAL, 'hour')).* FROM last_24_hours;
DROP MATERIALIZED VIEW IF EXISTS spender_growth_days;
CREATE MATERIALIZED VIEW IF NOT EXISTS spender_growth_days AS
SELECT (spender_growth(min, max, '1 day'::INTERVAL, 'day')).* FROM all_days;
DROP MATERIALIZED VIEW IF EXISTS spender_growth_months;
CREATE MATERIALIZED VIEW IF NOT EXISTS spender_growth_months AS
SELECT (spender_growth(min, max, '1 month'::INTERVAL, 'month')).* FROM all_months;
-- get items
CREATE OR REPLACE FUNCTION item_growth(min TIMESTAMP(3), max TIMESTAMP(3), ival INTERVAL, date_part TEXT)
RETURNS TABLE (t TIMESTAMP(3), comments BIGINT, jobs BIGINT, posts BIGINT, territories BIGINT, zaps BIGINT)
LANGUAGE plpgsql
AS $$
DECLARE
min_utc TIMESTAMP(3) := timezone('utc', min AT TIME ZONE 'America/Chicago');
BEGIN
RETURN QUERY
SELECT period.t, count(*) FILTER (WHERE type = 'COMMENT') as comments,
count(*) FILTER (WHERE type = 'JOB') as jobs,
count(*) FILTER (WHERE type = 'POST') as posts,
count(*) FILTER (WHERE type = 'TERRITORY') as territories,
count(*) FILTER (WHERE type = 'ZAP') as zaps
FROM generate_series(min, max, ival) period(t)
LEFT JOIN
((SELECT created_at,
CASE
WHEN "subName" = 'jobs' THEN 'JOB'
WHEN "parentId" IS NULL THEN 'POST'
ELSE 'COMMENT' END as type
FROM "Item"
WHERE created_at >= min_utc)
UNION ALL
(SELECT created_at, 'TERRITORY' as type
FROM "Sub"
WHERE created_at >= min_utc)
UNION ALL
(SELECT created_at, 'ZAP' as type
FROM "ItemAct"
WHERE act = 'TIP'
AND created_at >= min_utc)) u ON period.t = date_trunc(date_part, u.created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago')
GROUP BY period.t
ORDER BY period.t ASC;
END;
$$;
DROP MATERIALIZED VIEW IF EXISTS item_growth_hours;
CREATE MATERIALIZED VIEW IF NOT EXISTS item_growth_hours AS
SELECT (item_growth(min, max, '1 hour'::INTERVAL, 'hour')).* FROM last_24_hours;
DROP MATERIALIZED VIEW IF EXISTS item_growth_days;
CREATE MATERIALIZED VIEW IF NOT EXISTS item_growth_days AS
SELECT (item_growth(min, max, '1 day'::INTERVAL, 'day')).* FROM all_days;
DROP MATERIALIZED VIEW IF EXISTS item_growth_months;
CREATE MATERIALIZED VIEW IF NOT EXISTS item_growth_months AS
SELECT (item_growth(min, max, '1 month'::INTERVAL, 'month')).* FROM all_months;
-- get spending
CREATE OR REPLACE FUNCTION spending_growth(min TIMESTAMP(3), max TIMESTAMP(3), ival INTERVAL, date_part TEXT)
RETURNS TABLE (t TIMESTAMP(3), jobs BIGINT, boost BIGINT, fees BIGINT, tips BIGINT, donations BIGINT, territories BIGINT)
LANGUAGE plpgsql
AS $$
DECLARE
min_utc TIMESTAMP(3) := timezone('utc', min AT TIME ZONE 'America/Chicago');
BEGIN
RETURN QUERY
SELECT period.t,
coalesce(floor(sum(msats) FILTER (WHERE act = 'STREAM')/1000), 0)::BIGINT as jobs,
coalesce(floor(sum(msats) FILTER (WHERE act = 'BOOST')/1000), 0)::BIGINT as boost,
coalesce(floor(sum(msats) FILTER (WHERE act NOT IN ('BOOST', 'TIP', 'STREAM', 'DONATION'))/1000), 0)::BIGINT as fees,
coalesce(floor(sum(msats) FILTER (WHERE act = 'TIP')/1000), 0)::BIGINT as tips,
coalesce(floor(sum(msats) FILTER (WHERE act = 'DONATION')/1000), 0)::BIGINT as donations,
coalesce(floor(sum(msats) FILTER (WHERE act = 'TERRITORY')/1000), 0)::BIGINT as territories
FROM generate_series(min, max, ival) period(t)
LEFT JOIN
((SELECT "ItemAct".created_at, msats, act::text as act
FROM "ItemAct"
WHERE created_at >= min_utc)
UNION ALL
(SELECT created_at, sats * 1000 as msats, 'DONATION' as act
FROM "Donation"
WHERE created_at >= min_utc)
UNION ALL
(SELECT created_at, msats, 'TERRITORY' as act
FROM "SubAct"
WHERE type = 'BILLING'
AND created_at >= min_utc)
) u ON period.t = date_trunc(date_part, u.created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago')
GROUP BY period.t
ORDER BY period.t ASC;
END;
$$;
DROP MATERIALIZED VIEW IF EXISTS spending_growth_hours;
CREATE MATERIALIZED VIEW IF NOT EXISTS spending_growth_hours AS
SELECT (spending_growth(min, max, '1 hour'::INTERVAL, 'hour')).* FROM last_24_hours;
DROP MATERIALIZED VIEW IF EXISTS spending_growth_days;
CREATE MATERIALIZED VIEW IF NOT EXISTS spending_growth_days AS
SELECT (spending_growth(min, max, '1 day'::INTERVAL, 'day')).* FROM all_days;
DROP MATERIALIZED VIEW IF EXISTS spending_growth_months;
CREATE MATERIALIZED VIEW IF NOT EXISTS spending_growth_months AS
SELECT (spending_growth(min, max, '1 month'::INTERVAL, 'month')).* FROM all_months;
-- get stackers
CREATE OR REPLACE FUNCTION stackers_growth(min TIMESTAMP(3), max TIMESTAMP(3), ival INTERVAL, date_part TEXT)
RETURNS TABLE (t TIMESTAMP(3), "userId" INT, type TEXT)
LANGUAGE plpgsql
AS $$
DECLARE
min_utc TIMESTAMP(3) := timezone('utc', min AT TIME ZONE 'America/Chicago');
BEGIN
RETURN QUERY
SELECT period.t, u."userId", u.type
FROM generate_series(min, max, ival) period(t)
LEFT JOIN
((SELECT "ItemAct".created_at, "Item"."userId", CASE WHEN "Item"."parentId" IS NULL THEN 'POST' ELSE 'COMMENT' END as type
FROM "ItemAct"
JOIN "Item" on "ItemAct"."itemId" = "Item".id
WHERE "ItemAct".act = 'TIP'
AND "ItemAct".created_at >= min_utc)
UNION ALL
(SELECT created_at, "Earn"."userId", 'EARN' as type
FROM "Earn"
WHERE created_at >= min_utc)
UNION ALL
(SELECT created_at, "ReferralAct"."referrerId" as "userId", 'REFERRAL' as type
FROM "ReferralAct"
WHERE created_at >= min_utc)
UNION ALL
(SELECT created_at, "SubAct"."userId", 'REVENUE' as type
FROM "SubAct"
WHERE "SubAct".type = 'REVENUE'
AND created_at >= min_utc)
) u ON period.t = date_trunc(date_part, u.created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago')
GROUP BY period.t, u."userId", u.type
ORDER BY period.t ASC;
END;
$$;
DROP MATERIALIZED VIEW IF EXISTS stackers_growth_hours;
CREATE MATERIALIZED VIEW IF NOT EXISTS stackers_growth_hours AS
SELECT (stackers_growth(min, max, '1 hour'::INTERVAL, 'hour')).* FROM last_24_hours;
DROP MATERIALIZED VIEW IF EXISTS stackers_growth_days;
CREATE MATERIALIZED VIEW IF NOT EXISTS stackers_growth_days AS
SELECT (stackers_growth(min, max, '1 day'::INTERVAL, 'day')).* FROM all_days;
DROP MATERIALIZED VIEW IF EXISTS stackers_growth_months;
CREATE MATERIALIZED VIEW IF NOT EXISTS stackers_growth_months AS
SELECT (stackers_growth(min, max, '1 month'::INTERVAL, 'month')).* FROM all_months;
-- get stacking
CREATE OR REPLACE FUNCTION stacking_growth(min TIMESTAMP(3), max TIMESTAMP(3), ival INTERVAL, date_part TEXT)
RETURNS TABLE (t TIMESTAMP(3), rewards BIGINT, posts BIGINT, comments BIGINT, referrals BIGINT, territories BIGINT)
LANGUAGE plpgsql
AS $$
DECLARE
min_utc TIMESTAMP(3) := timezone('utc', min AT TIME ZONE 'America/Chicago');
BEGIN
RETURN QUERY
SELECT period.t,
coalesce(floor(sum(airdrop)/1000),0)::BIGINT as rewards,
coalesce(floor(sum(post)/1000),0)::BIGINT as posts,
coalesce(floor(sum(comment)/1000),0)::BIGINT as comments,
coalesce(floor(sum(referral)/1000),0)::BIGINT as referrals,
coalesce(floor(sum(revenue)/1000),0)::BIGINT as territories
FROM generate_series(min, max, ival) period(t)
LEFT JOIN
((SELECT "ItemAct".created_at, 0 as airdrop,
CASE WHEN "Item"."parentId" IS NULL THEN 0 ELSE "ItemAct".msats END as comment,
CASE WHEN "Item"."parentId" IS NULL THEN "ItemAct".msats ELSE 0 END as post,
0 as referral,
0 as revenue
FROM "ItemAct"
JOIN "Item" on "ItemAct"."itemId" = "Item".id
WHERE "ItemAct".act = 'TIP'
AND "ItemAct".created_at >= min_utc)
UNION ALL
(SELECT created_at, 0 as airdrop, 0 as post, 0 as comment, msats as referral, 0 as revenue
FROM "ReferralAct"
WHERE created_at >= min_utc)
UNION ALL
(SELECT created_at, msats as airdrop, 0 as post, 0 as comment, 0 as referral, 0 as revenue
FROM "Earn"
WHERE created_at >= min_utc)
UNION ALL
(SELECT created_at, 0 as airdrop, 0 as post, 0 as comment, 0 as referral, msats as revenue
FROM "SubAct"
WHERE type = 'REVENUE'
AND created_at >= min_utc)
) u ON period.t = date_trunc(date_part, u.created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago')
GROUP BY period.t
ORDER BY period.t ASC;
END;
$$;
DROP MATERIALIZED VIEW IF EXISTS stacking_growth_hours;
CREATE MATERIALIZED VIEW IF NOT EXISTS stacking_growth_hours AS
SELECT (stacking_growth(min, max, '1 hour'::INTERVAL, 'hour')).* FROM last_24_hours;
DROP MATERIALIZED VIEW IF EXISTS stacking_growth_days;
CREATE MATERIALIZED VIEW IF NOT EXISTS stacking_growth_days AS
SELECT (stacking_growth(min, max, '1 day'::INTERVAL, 'day')).* FROM all_days;
DROP MATERIALIZED VIEW IF EXISTS stacking_growth_months;
CREATE MATERIALIZED VIEW IF NOT EXISTS stacking_growth_months AS
SELECT (stacking_growth(min, max, '1 month'::INTERVAL, 'month')).* FROM all_months;
-- for user top stats
CREATE OR REPLACE FUNCTION user_stats(min TIMESTAMP(3), max TIMESTAMP(3), ival INTERVAL, date_part TEXT)
RETURNS TABLE (
t TIMESTAMP(3), id INTEGER, comments BIGINT, posts BIGINT, territories BIGINT,
referrals BIGINT, msats_tipped BIGINT, msats_rewards BIGINT, msats_referrals BIGINT,
msats_revenue BIGINT, msats_stacked BIGINT, msats_fees BIGINT, msats_donated BIGINT,
msats_billing BIGINT, msats_spent BIGINT)
LANGUAGE plpgsql
AS $$
DECLARE
min_utc TIMESTAMP(3) := timezone('utc', min AT TIME ZONE 'America/Chicago');
BEGIN
RETURN QUERY
SELECT period.t,
"userId" as id,
-- counts
(sum(quantity) FILTER (WHERE type = 'COMMENT'))::BIGINT as comments,
(sum(quantity) FILTER (WHERE type = 'POSTS'))::BIGINT as posts,
(sum(quantity) FILTER (WHERE type = 'TERRITORY'))::BIGINT as territories,
(sum(quantity) FILTER (WHERE type = 'REFERRAL'))::BIGINT as referrals,
-- stacking
(sum(quantity) FILTER (WHERE type = 'TIPPEE'))::BIGINT as msats_tipped,
(sum(quantity) FILTER (WHERE type = 'EARN'))::BIGINT as msats_rewards,
(sum(quantity) FILTER (WHERE type = 'REFERRAL_ACT'))::BIGINT as msats_referrals,
(sum(quantity) FILTER (WHERE type = 'REVENUE'))::BIGINT as msats_revenue,
(sum(quantity) FILTER (WHERE type IN ('TIPPEE', 'EARN', 'REFERRAL_ACT', 'REVENUE')))::BIGINT as msats_stacked,
-- spending
(sum(quantity) FILTER (WHERE type IN ('BOOST', 'TIP', 'FEE', 'STREAM', 'POLL', 'DONT_LIKE_THIS')))::BIGINT as msats_fees,
(sum(quantity) FILTER (WHERE type = 'DONATION'))::BIGINT as msats_donated,
(sum(quantity) FILTER (WHERE type = 'TERRITORY'))::BIGINT as msats_billing,
(sum(quantity) FILTER (WHERE type IN ('BOOST', 'TIP', 'FEE', 'STREAM', 'POLL', 'DONT_LIKE_THIS', 'DONATION', 'TERRITORY')))::BIGINT as msats_spent
FROM generate_series(min, max, ival) period(t)
LEFT JOIN
((SELECT "userId", msats as quantity, act::TEXT as type, created_at
FROM "ItemAct"
WHERE created_at >= min_utc)
UNION ALL
(SELECT "userId", sats*1000 as quantity, 'DONATION' as type, created_at
FROM "Donation"
WHERE created_at >= min_utc)
UNION ALL
(SELECT "userId", 1 as quantity,
CASE WHEN "Item"."parentId" IS NULL THEN 'POST' ELSE 'COMMENT' END as type, created_at
FROM "Item"
WHERE created_at >= min_utc)
UNION ALL
(SELECT "referrerId" as "userId", 1 as quantity, 'REFERRAL' as type, created_at
FROM users
WHERE "referrerId" IS NOT NULL
AND created_at >= min_utc)
UNION ALL
-- tips accounting for forwarding
(SELECT "Item"."userId", floor("ItemAct".msats * (1-COALESCE(sum("ItemForward".pct)/100.0, 0))) as quantity, 'TIPPEE' as type, "ItemAct".created_at
FROM "ItemAct"
JOIN "Item" on "ItemAct"."itemId" = "Item".id
LEFT JOIN "ItemForward" on "ItemForward"."itemId" = "Item".id
WHERE "ItemAct".act = 'TIP'
AND "ItemAct".created_at >= min_utc
GROUP BY "Item"."userId", "ItemAct".id, "ItemAct".msats, "ItemAct".created_at)
UNION ALL
-- tips where stacker is a forwardee
(SELECT "ItemForward"."userId", floor("ItemAct".msats*("ItemForward".pct/100.0)) as quantity, 'TIPPEE' as type, "ItemAct".created_at
FROM "ItemAct"
JOIN "Item" on "ItemAct"."itemId" = "Item".id
JOIN "ItemForward" on "ItemForward"."itemId" = "Item".id
WHERE "ItemAct".act = 'TIP'
AND "ItemAct".created_at >= min_utc)
UNION ALL
(SELECT "userId", msats as quantity, 'EARN' as type, created_at
FROM "Earn"
WHERE created_at >= min_utc)
UNION ALL
(SELECT "referrerId" as "userId", msats as quantity, 'REFERRAL_ACT' as type, created_at
FROM "ReferralAct"
WHERE created_at >= min_utc)
UNION ALL
(SELECT "userId", msats as quantity, type::TEXT as type, created_at
FROM "SubAct"
WHERE created_at >= min_utc)
UNION ALL
(SELECT "userId", 1 as quantity, 'TERRITORY' as type, created_at
FROM "Sub"
WHERE status <> 'STOPPED'
AND created_at >= min_utc)
) u ON period.t = date_trunc(date_part, u.created_at AT TIME ZONE 'UTC' AT TIME ZONE 'America/Chicago')
GROUP BY "userId", period.t
ORDER BY period.t ASC;
END;
$$;
DROP MATERIALIZED VIEW IF EXISTS user_stats_hours;
CREATE MATERIALIZED VIEW IF NOT EXISTS user_stats_hours AS
SELECT (user_stats(min, max, '1 hour'::INTERVAL, 'hour')).* FROM last_24_hours;
DROP MATERIALIZED VIEW IF EXISTS user_stats_days;
CREATE MATERIALIZED VIEW IF NOT EXISTS user_stats_days AS
SELECT (user_stats(min, max, '1 day'::INTERVAL, 'day')).* FROM all_days;
DROP MATERIALIZED VIEW IF EXISTS user_stats_months;
CREATE MATERIALIZED VIEW IF NOT EXISTS user_stats_months AS
SELECT (user_stats(min, max, '1 month'::INTERVAL, 'month')).* FROM all_months;
-- indices on hours
CREATE UNIQUE INDEX IF NOT EXISTS user_stats_hours_idx ON user_stats_hours(t, id);
CREATE UNIQUE INDEX IF NOT EXISTS reg_growth_hours_idx ON reg_growth_hours(t);
CREATE UNIQUE INDEX IF NOT EXISTS spender_growth_hours_idx ON spender_growth_hours(t, "userId", type);
CREATE UNIQUE INDEX IF NOT EXISTS item_growth_hour_idx ON item_growth_hours(t);
CREATE UNIQUE INDEX IF NOT EXISTS spending_growth_hours_idx ON spending_growth_hours(t);
CREATE UNIQUE INDEX IF NOT EXISTS stackers_growth_hours_idx ON stackers_growth_hours(t, "userId", type);
CREATE UNIQUE INDEX IF NOT EXISTS stacking_growth_hours_idx ON stacking_growth_hours(t);
-- indices on days
CREATE UNIQUE INDEX IF NOT EXISTS user_stats_days_idx ON user_stats_days(t, id);
CREATE UNIQUE INDEX IF NOT EXISTS reg_growth_days_idx ON reg_growth_days(t);
CREATE UNIQUE INDEX IF NOT EXISTS spender_growth_days_idx ON spender_growth_days(t, "userId", type);
CREATE UNIQUE INDEX IF NOT EXISTS item_growth_days_idx ON item_growth_days(t);
CREATE UNIQUE INDEX IF NOT EXISTS spending_growth_days_idx ON spending_growth_days(t);
CREATE UNIQUE INDEX IF NOT EXISTS stackers_growth_days_idx ON stackers_growth_days(t, "userId", type);
CREATE UNIQUE INDEX IF NOT EXISTS stacking_growth_days_idx ON stacking_growth_days(t);
-- indices on months
CREATE UNIQUE INDEX IF NOT EXISTS user_stats_months_idx ON user_stats_months(t, id);
CREATE UNIQUE INDEX IF NOT EXISTS reg_growth_months_idx ON reg_growth_months(t);
CREATE UNIQUE INDEX IF NOT EXISTS spender_growth_months_idx ON spender_growth_months(t, "userId", type);
CREATE UNIQUE INDEX IF NOT EXISTS item_growth_months_idx ON item_growth_months(t);
CREATE UNIQUE INDEX IF NOT EXISTS spending_growth_months_idx ON spending_growth_months(t);
CREATE UNIQUE INDEX IF NOT EXISTS stackers_growth_months_idx ON stackers_growth_months(t, "userId", type);
CREATE UNIQUE INDEX IF NOT EXISTS stacking_growth_months_idx ON stacking_growth_months(t);
CREATE OR REPLACE FUNCTION create_period_views_job()
RETURNS INTEGER
LANGUAGE plpgsql
AS $$
DECLARE
BEGIN
UPDATE pgboss.schedule SET name = 'views-days', data = json_build_object('period', 'days') WHERE name = 'views';
INSERT INTO pgboss.schedule (name, data, cron, timezone)
VALUES ('views-hours', json_build_object('period', 'hours'), '0 * * * *', 'America/Chicago') ON CONFLICT DO NOTHING;
INSERT INTO pgboss.schedule (name, data, cron, timezone)
VALUES ('views-months', json_build_object('period', 'months'), '0 0 1 * *', 'America/Chicago') ON CONFLICT DO NOTHING;
return 0;
EXCEPTION WHEN OTHERS THEN
return 0;
END;
$$;
SELECT create_period_views_job();
DROP FUNCTION create_period_views_job();

View File

@ -91,7 +91,7 @@ async function work () {
await boss.work('streak', jobWrapper(computeStreaks)) await boss.work('streak', jobWrapper(computeStreaks))
await boss.work('checkStreak', jobWrapper(checkStreak)) await boss.work('checkStreak', jobWrapper(checkStreak))
await boss.work('nip57', jobWrapper(nip57)) await boss.work('nip57', jobWrapper(nip57))
await boss.work('views', jobWrapper(views)) await boss.work('views-*', jobWrapper(views))
await boss.work('rankViews', jobWrapper(rankViews)) await boss.work('rankViews', jobWrapper(rankViews))
await boss.work('imgproxy', jobWrapper(imgproxy)) await boss.work('imgproxy', jobWrapper(imgproxy))
await boss.work('deleteItem', jobWrapper(deleteItem)) await boss.work('deleteItem', jobWrapper(deleteItem))

View File

@ -1,9 +1,10 @@
const viewPrefixes = ['reg_growth', 'spender_growth', 'item_growth', 'spending_growth',
'stackers_growth', 'stacking_growth', 'user_stats']
// this is intended to be run everyday after midnight CT // this is intended to be run everyday after midnight CT
export async function views ({ models }) { export async function views ({ data: { period } = { period: 'days' }, models }) {
for (const view of ['reg_growth_days', 'spender_growth_days', 'item_growth_days', for (const view of viewPrefixes) {
'spending_growth_days', 'stackers_growth_days', 'stacking_growth_days', await models.$queryRawUnsafe(`REFRESH MATERIALIZED VIEW CONCURRENTLY ${view}_${period}`)
'user_stats_days']) {
await models.$queryRawUnsafe(`REFRESH MATERIALIZED VIEW CONCURRENTLY ${view}`)
} }
} }