Add ranked territories to 'top' page (#828)

* add subViewGroup function to create view to read sub stats from

* add topSubs resolver to graphql query

* add TOP_SUBS query fragment

* add SUB_SORTS for top territory sorting

* add custom cache policy for topSubs

* add territories to top header select

* add top territories page

* add db views for sub stats

* configure sub_stats views to refresh by worker

* filter rows with empty subName

* update msats_spent calculation to include all ItemAct in sub

---------

Co-authored-by: Keyan <34140557+huumn@users.noreply.github.com>
This commit is contained in:
mzivil 2024-02-14 15:27:00 -05:00 committed by GitHub
parent b3498fe277
commit f59ee5df17
No known key found for this signature in database
GPG Key ID: B5690EEEBB952194
11 changed files with 322 additions and 6 deletions

View File

@ -46,6 +46,26 @@ export function viewGroup (range, view) {
) u` ) u`
} }
export function subViewGroup (range) {
const unit = timeUnitForRange(range)
return `(
(SELECT *
FROM sub_stats_days
WHERE ${viewIntervalClause(range, 'sub_stats_days')})
UNION ALL
(SELECT *
FROM sub_stats_hours
WHERE ${viewIntervalClause(range, 'sub_stats_hours')}
${unit === 'hour' ? '' : 'AND "sub_stats_hours".t >= date_trunc(\'day\', timezone(\'America/Chicago\', now()))'})
UNION ALL
(SELECT * FROM
sub_stats(
date_trunc('hour', timezone('America/Chicago', now())),
date_trunc('hour', timezone('America/Chicago', now())), '1 hour'::INTERVAL, 'hour')
WHERE "sub_stats".t >= date_trunc('${unit}', timezone('America/Chicago', $1)))
)`
}
export default { export default {
Query: { Query: {
registrationGrowth: async (parent, { when, from, to }, { models }) => { registrationGrowth: async (parent, { when, from, to }, { models }) => {

View File

@ -1,9 +1,11 @@
import { GraphQLError } from 'graphql' import { GraphQLError } from 'graphql'
import { serializeInvoicable } from './serial' import { serializeInvoicable } from './serial'
import { TERRITORY_COST_MONTHLY, TERRITORY_COST_ONCE, TERRITORY_COST_YEARLY } from '../../lib/constants' import { TERRITORY_COST_MONTHLY, TERRITORY_COST_ONCE, TERRITORY_COST_YEARLY } from '../../lib/constants'
import { datePivot } from '../../lib/time' import { datePivot, whenRange } from '../../lib/time'
import { ssValidate, territorySchema } from '../../lib/validate' import { ssValidate, territorySchema } from '../../lib/validate'
import { nextBilling, nextNextBilling } from '../../lib/territory' import { nextBilling, nextNextBilling } from '../../lib/territory'
import { decodeCursor, LIMIT, nextCursorEncoded } from '../../lib/cursor'
import { subViewGroup } from './growth'
export function paySubQueries (sub, models) { export function paySubQueries (sub, models) {
if (sub.billingType === 'ONCE') { if (sub.billingType === 'ONCE') {
@ -119,6 +121,38 @@ export default {
}) })
return latest?.createdAt return latest?.createdAt
},
topSubs: async (parent, { cursor, when, by, from, to, limit = LIMIT }, { models, me }) => {
const decodedCursor = decodeCursor(cursor)
const range = whenRange(when, from, to || decodeCursor.time)
let column
switch (by) {
case 'revenue': column = 'revenue'; break
case 'spent': column = 'spent'; break
case 'posts': column = 'nposts'; break
case 'comments': column = 'ncomments'; break
default: column = 'stacked'; break
}
const subs = await models.$queryRawUnsafe(`
SELECT "Sub".*,
COALESCE(floor(sum(msats_revenue)/1000), 0) as revenue,
COALESCE(floor(sum(msats_stacked)/1000), 0) as stacked,
COALESCE(floor(sum(msats_spent)/1000), 0) as spent,
COALESCE(sum(posts), 0) as nposts,
COALESCE(sum(comments), 0) as ncomments
FROM ${subViewGroup(range)} ss
JOIN "Sub" on "Sub".name = ss.sub_name
GROUP BY "Sub".name
ORDER BY ${column} DESC NULLS LAST, "Sub".created_at ASC
OFFSET $3
LIMIT $4`, ...range, decodedCursor.offset, limit)
return {
cursor: subs.length === limit ? nextCursorEncoded(decodedCursor, limit) : null,
subs
}
} }
}, },
Mutation: { Mutation: {
@ -183,6 +217,7 @@ export default {
} }
}, },
Sub: { Sub: {
optional: sub => sub,
user: async (sub, args, { models }) => { user: async (sub, args, { models }) => {
if (sub.user) { if (sub.user) {
return sub.user return sub.user
@ -191,6 +226,16 @@ export default {
}, },
meMuteSub: async (sub, args, { models }) => { meMuteSub: async (sub, args, { models }) => {
return sub.meMuteSub || sub.MuteSub?.length > 0 return sub.meMuteSub || sub.MuteSub?.length > 0
},
nposts: async (sub, { when, from, to }, { models }) => {
if (typeof sub.nposts !== 'undefined') {
return sub.nposts
}
},
ncomments: async (sub, { when, from, to }, { models }) => {
if (typeof sub.ncomments !== 'undefined') {
return sub.ncomments
}
} }
} }
} }

View File

@ -5,6 +5,12 @@ export default gql`
sub(name: String): Sub sub(name: String): Sub
subLatestPost(name: String!): String subLatestPost(name: String!): String
subs: [Sub!]! subs: [Sub!]!
topSubs(cursor: String, when: String, from: String, to: String, by: String, limit: Limit): Subs
}
type Subs {
cursor: String
subs: [Sub!]!
} }
extend type Mutation { extend type Mutation {
@ -36,5 +42,18 @@ export default gql`
moderatedCount: Int! moderatedCount: Int!
meMuteSub: Boolean! meMuteSub: Boolean!
nsfw: Boolean! nsfw: Boolean!
nposts(when: String, from: String, to: String): Int!
ncomments(when: String, from: String, to: String): Int!
optional: SubOptional!
}
type SubOptional {
"""
conditionally private
"""
stacked(when: String, from: String, to: String): Int
spent(when: String, from: String, to: String): Int
revenue(when: String, from: String, to: String): Int
} }
` `

View File

@ -0,0 +1,98 @@
import Link from 'next/link'
import { abbrNum, numWithUnits } from '../lib/format'
import styles from './item.module.css'
import { useEffect, useMemo, useState } from 'react'
import { useQuery } from '@apollo/client'
import MoreFooter from './more-footer'
import { useData } from './use-data'
// all of this nonsense is to show the stat we are sorting by first
const Revenue = ({ sub }) => (sub.optional.revenue !== null && <span>{abbrNum(sub.optional.revenue)} revenue</span>)
const Stacked = ({ sub }) => (sub.optional.stacked !== null && <span>{abbrNum(sub.optional.stacked)} stacked</span>)
const Spent = ({ sub }) => (sub.optional.spent !== null && <span>{abbrNum(sub.optional.spent)} spent</span>)
const Posts = ({ sub }) => (
<span>
{numWithUnits(sub.nposts, { unitSingular: 'post', unitPlural: 'posts' })}
</span>)
const Comments = ({ sub }) => (
<span>
{numWithUnits(sub.ncomments, { unitSingular: 'comment', unitPlural: 'comments' })}
</span>)
const Separator = () => (<span> \ </span>)
const STAT_POS = {
stacked: 0,
revenue: 1,
spent: 2,
posts: 3,
comments: 4
}
const STAT_COMPONENTS = [Stacked, Revenue, Spent, Posts, Comments]
function separate (arr, separator) {
return arr.flatMap((x, i) => i < arr.length - 1 ? [x, separator] : [x])
}
export default function TerritoryList ({ ssrData, query, variables, destructureData }) {
const { data, fetchMore } = useQuery(query, { variables })
const dat = useData(data, ssrData)
const [statComps, setStatComps] = useState(separate(STAT_COMPONENTS, Separator))
useEffect(() => {
// shift the stat we are sorting by to the front
const comps = [...STAT_COMPONENTS]
setStatComps(separate([...comps.splice(STAT_POS[variables?.by || 0], 1), ...comps], Separator))
}, [variables?.by])
const { subs, cursor } = useMemo(() => {
if (!dat) return {}
if (destructureData) {
return destructureData(dat)
} else {
return dat
}
}, [dat])
if (!dat) {
return <SubsSkeleton />
}
return (
<>
{subs?.map(sub => (
<div className={`${styles.item} mb-2`} key={sub.name}>
<div className={styles.hunk}>
<Link href={`/~${sub.name}`} className={`${styles.title} d-inline-flex align-items-center text-reset`}>
{sub.name}
</Link>
<div className={styles.other}>
{statComps.map((Comp, i) => <Comp key={i} sub={sub} />)}
</div>
</div>
</div>
))}
<MoreFooter cursor={cursor} count={subs?.length} fetchMore={fetchMore} Skeleton={SubsSkeleton} noMoreText='NO MORE' />
</>
)
}
export function SubsSkeleton () {
const subs = new Array(21).fill(null)
return (
<div>{subs.map((_, i) => (
<div className={`${styles.item} ${styles.skeleton} mb-2`} key={i}>
<div className={styles.hunk}>
<div className={`${styles.name} clouds text-reset`} />
<div className={styles.other}>
<span className={`${styles.otherItem} clouds`} />
<span className={`${styles.otherItem} clouds`} />
<span className={`${styles.otherItem} ${styles.otherItemLonger} clouds`} />
<span className={`${styles.otherItem} ${styles.otherItemLonger} clouds`} />
</div>
</div>
</div>
))}
</div>
)
}

View File

@ -1,6 +1,6 @@
import { useRouter } from 'next/router' import { useRouter } from 'next/router'
import { Form, Select, DatePicker } from './form' import { Form, Select, DatePicker } from './form'
import { ITEM_SORTS, USER_SORTS, WHENS } from '../lib/constants' import { ITEM_SORTS, SUB_SORTS, USER_SORTS, WHENS } from '../lib/constants'
import { whenToFrom } from '../lib/time' import { whenToFrom } from '../lib/time'
export default function TopHeader ({ sub, cat }) { export default function TopHeader ({ sub, cat }) {
@ -21,7 +21,8 @@ export default function TopHeader ({ sub, cat }) {
if (typeof query.by !== 'undefined') { if (typeof query.by !== 'undefined') {
if (query.by === '' || if (query.by === '' ||
(what === 'stackers' && (query.by === 'stacked' || !USER_SORTS.includes(query.by))) || (what === 'stackers' && (query.by === 'stacked' || !USER_SORTS.includes(query.by))) ||
(what !== 'stackers' && (query.by === 'zaprank' || !ITEM_SORTS.includes(query.by)))) { (what === 'territories' && (query.by === 'stacked' || !SUB_SORTS.includes(query.by))) ||
(['posts', 'comments'].includes(what) && (query.by === 'zaprank' || !ITEM_SORTS.includes(query.by)))) {
delete query.by delete query.by
} }
} }
@ -54,7 +55,7 @@ export default function TopHeader ({ sub, cat }) {
name='what' name='what'
size='sm' size='sm'
overrideValue={what} overrideValue={what}
items={router?.query?.sub ? ['posts', 'comments'] : ['posts', 'comments', 'stackers', 'cowboys']} items={router?.query?.sub ? ['posts', 'comments'] : ['posts', 'comments', 'stackers', 'cowboys', 'territories']}
/> />
{cat !== 'cowboys' && {cat !== 'cowboys' &&
<> <>
@ -65,7 +66,7 @@ export default function TopHeader ({ sub, cat }) {
name='by' name='by'
size='sm' size='sm'
overrideValue={by} overrideValue={by}
items={cat === 'stackers' ? USER_SORTS : ITEM_SORTS} items={sortItemsForCategory(cat)}
/> />
for for
<Select <Select
@ -99,3 +100,14 @@ export default function TopHeader ({ sub, cat }) {
</div> </div>
) )
} }
function sortItemsForCategory (cat) {
switch (cat) {
case 'stackers':
return USER_SORTS
case 'territories':
return SUB_SORTS
default:
return ITEM_SORTS
}
}

View File

@ -114,3 +114,22 @@ export const SUB_PAY = gql`
...SubFullFields ...SubFullFields
} }
}` }`
export const TOP_SUBS = gql`
query TopSubs($cursor: String, $when: String, $from: String, $to: String, $by: String, ) {
topSubs(cursor: $cursor, when: $when, from: $from, to: $to, by: $by) {
subs {
name
ncomments(when: $when, from: $from, to: $to)
nposts(when: $when, from: $from, to: $to)
optional {
stacked(when: $when, from: $from, to: $to)
spent(when: $when, from: $from, to: $to)
revenue(when: $when, from: $from, to: $to)
}
}
cursor
}
}
`

View File

@ -55,6 +55,19 @@ function getClient (uri) {
return incoming return incoming
} }
}, },
topSubs: {
keyArgs: ['when', 'by', 'from', 'to', 'limit'],
merge (existing, incoming, { args }) {
if (isFirstPage(incoming.cursor, existing?.subs, args.limit)) {
return incoming
}
return {
cursor: incoming.cursor,
subs: [...(existing?.subs || []), ...incoming.subs]
}
}
},
topUsers: { topUsers: {
keyArgs: ['when', 'by', 'from', 'to', 'limit'], keyArgs: ['when', 'by', 'from', 'to', 'limit'],
merge (existing, incoming, { args }) { merge (existing, incoming, { args }) {

View File

@ -44,6 +44,7 @@ export const DONT_LIKE_THIS_COST = 1
export const COMMENT_TYPE_QUERY = ['comments', 'freebies', 'outlawed', 'borderland', 'all', 'bookmarks'] export const COMMENT_TYPE_QUERY = ['comments', 'freebies', 'outlawed', 'borderland', 'all', 'bookmarks']
export const USER_SORTS = ['stacked', 'spent', 'comments', 'posts', 'referrals'] export const USER_SORTS = ['stacked', 'spent', 'comments', 'posts', 'referrals']
export const ITEM_SORTS = ['zaprank', 'comments', 'sats'] export const ITEM_SORTS = ['zaprank', 'comments', 'sats']
export const SUB_SORTS = ['stacked', 'revenue', 'spent', 'posts', 'comments']
export const WHENS = ['day', 'week', 'month', 'year', 'forever', 'custom'] export const WHENS = ['day', 'week', 'month', 'year', 'forever', 'custom']
export const ITEM_TYPES_USER = ['all', 'posts', 'comments', 'bounties', 'links', 'discussions', 'polls', 'freebies', 'jobs', 'bookmarks'] export const ITEM_TYPES_USER = ['all', 'posts', 'comments', 'bounties', 'links', 'discussions', 'polls', 'freebies', 'jobs', 'bookmarks']
export const ITEM_TYPES = ['all', 'posts', 'comments', 'bounties', 'links', 'discussions', 'polls', 'freebies', 'bios', 'jobs'] export const ITEM_TYPES = ['all', 'posts', 'comments', 'bounties', 'links', 'discussions', 'polls', 'freebies', 'bios', 'jobs']

View File

@ -0,0 +1,25 @@
import Layout from '../../../../components/layout'
import { useRouter } from 'next/router'
import { getGetServerSideProps } from '../../../../api/ssrApollo'
import TopHeader from '../../../../components/top-header'
import { TOP_SUBS } from '../../../../fragments/subs'
import TerritoryList from '../../../../components/territory-list'
export const getServerSideProps = getGetServerSideProps({ query: TOP_SUBS })
export default function Index ({ ssrData }) {
const router = useRouter()
const variables = { ...router.query }
return (
<Layout>
<TopHeader cat='territories' />
<TerritoryList
ssrData={ssrData}
query={TOP_SUBS}
variables={variables}
destructureData={data => data.topSubs}
/>
</Layout>
)
}

View File

@ -0,0 +1,64 @@
CREATE OR REPLACE FUNCTION sub_stats(min TIMESTAMP(3), max TIMESTAMP(3), ival INTERVAL, date_part TEXT)
RETURNS TABLE (
t TIMESTAMP(3), sub_name CITEXT, comments BIGINT, posts BIGINT,
msats_revenue BIGINT, msats_stacked 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,
"subName" as sub_name,
(sum(quantity) FILTER (WHERE type = 'COMMENT'))::BIGINT as comments,
(sum(quantity) FILTER (WHERE type = 'POST'))::BIGINT as posts,
(sum(quantity) FILTER (WHERE type = 'REVENUE'))::BIGINT as msats_revenue,
(sum(quantity) FILTER (WHERE type = 'TIP'))::BIGINT as msats_stacked,
(sum(quantity) FILTER (WHERE type IN ('BOOST', 'TIP', 'FEE', 'STREAM', 'POLL', 'DONT_LIKE_THIS', 'VOTE')))::BIGINT as msats_spent
FROM generate_series(min, max, ival) period(t)
LEFT JOIN (
-- For msats_spent and msats_stacked
(SELECT "subName", "ItemAct"."msats" as quantity, act::TEXT as type, "ItemAct"."created_at"
FROM "ItemAct"
JOIN "Item" ON "Item"."id" = "ItemAct"."itemId"
WHERE "ItemAct"."created_at" >= min_utc
AND "subName" IS NOT NULL
AND act = 'TIP')
UNION ALL
(SELECT "subName", 1 as quantity, 'POST' as type, created_at
FROM "Item"
WHERE created_at >= min_utc
AND "Item"."parentId" IS NULL
AND "subName" IS NOT NULL)
UNION ALL
(SELECT root."subName", 1 as quantity, 'COMMENT' as type, "Item"."created_at"
FROM "Item"
JOIN "Item" root ON "Item"."rootId" = root."id"
WHERE "Item"."created_at" >= min_utc
AND root."subName" IS NOT NULL)
UNION ALL
-- For msats_revenue
(SELECT "subName", msats as quantity, type::TEXT as type, created_at
FROM "SubAct"
WHERE 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 "subName", period.t
ORDER BY period.t ASC;
END;
$$;
DROP MATERIALIZED VIEW IF EXISTS sub_stats_hours;
CREATE MATERIALIZED VIEW IF NOT EXISTS sub_stats_hours AS
SELECT (sub_stats(min, max, '1 hour'::INTERVAL, 'hour')).* FROM last_24_hours;
DROP MATERIALIZED VIEW IF EXISTS sub_stats_days;
CREATE MATERIALIZED VIEW IF NOT EXISTS sub_stats_days AS
SELECT (sub_stats(min, max, '1 day'::INTERVAL, 'day')).* FROM all_days;
DROP MATERIALIZED VIEW IF EXISTS sub_stats_months;
CREATE MATERIALIZED VIEW IF NOT EXISTS sub_stats_months AS
SELECT (sub_stats(min, max, '1 month'::INTERVAL, 'month')).* FROM all_months;
CREATE UNIQUE INDEX IF NOT EXISTS sub_stats_hours_idx ON sub_stats_hours(t, sub_name);
CREATE UNIQUE INDEX IF NOT EXISTS sub_stats_days_idx ON sub_stats_days(t, sub_name);
CREATE UNIQUE INDEX IF NOT EXISTS sub_stats_months_idx ON sub_stats_months(t, sub_name);

View File

@ -1,7 +1,7 @@
import { PrismaClient } from '@prisma/client' import { PrismaClient } from '@prisma/client'
const viewPrefixes = ['reg_growth', 'spender_growth', 'item_growth', 'spending_growth', const viewPrefixes = ['reg_growth', 'spender_growth', 'item_growth', 'spending_growth',
'stackers_growth', 'stacking_growth', 'user_stats'] 'stackers_growth', 'stacking_growth', 'user_stats', 'sub_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 ({ data: { period } = { period: 'days' } }) { export async function views ({ data: { period } = { period: 'days' } }) {