materialize dashboard in views

This commit is contained in:
keyan 2023-05-18 18:41:56 -05:00
parent f6b4de24f0
commit 0a3f5fd201
8 changed files with 342 additions and 11 deletions

View File

@ -52,9 +52,29 @@ export function intervalClause (when, table, and) {
return `"${table}".created_at >= now_utc() - interval '${interval(when)}' ${and ? 'AND' : ''} `
}
export function viewIntervalClause (when, view, and) {
if (when === 'forever') {
return and ? '' : 'TRUE'
}
return `"${view}".day >= date_trunc('day', timezone('America/Chicago', now() - interval '${interval(when)}')) ${and ? 'AND' : ''} `
}
export default {
Query: {
registrationGrowth: async (parent, { when }, { models }) => {
if (when !== 'day') {
return await models.$queryRaw(`
SELECT date_trunc('${timeUnit(when)}', day) as time, json_build_array(
json_build_object('name', 'referrals', 'value', sum(referrals)),
json_build_object('name', 'organic', 'value', sum(organic))
) AS data
FROM reg_growth_days
WHERE ${viewIntervalClause(when, 'reg_growth_days', false)}
GROUP BY time
ORDER BY time ASC`)
}
return await models.$queryRaw(
`${withClause(when)}
SELECT time, json_build_array(
@ -67,6 +87,22 @@ export default {
ORDER BY time ASC`)
},
spenderGrowth: async (parent, { when }, { models }) => {
if (when !== 'day') {
return await models.$queryRaw(`
SELECT date_trunc('${timeUnit(when)}', day) as time, json_build_array(
json_build_object('name', 'any', 'value', sum("any")),
json_build_object('name', 'jobs', 'value', sum(jobs)),
json_build_object('name', 'boost', 'value', sum(boost)),
json_build_object('name', 'fees', 'value', sum(fees)),
json_build_object('name', 'tips', 'value', sum(tips)),
json_build_object('name', 'donation', 'value', sum(donations))
) AS data
FROM spender_growth_days
WHERE ${viewIntervalClause(when, 'spender_growth_days', false)}
GROUP BY time
ORDER BY time ASC`)
}
return await models.$queryRaw(
`${withClause(when)}
SELECT time, json_build_array(
@ -90,6 +126,19 @@ export default {
ORDER BY time ASC`)
},
itemGrowth: async (parent, { when }, { models }) => {
if (when !== 'day') {
return await models.$queryRaw(`
SELECT date_trunc('${timeUnit(when)}', day) as time, json_build_array(
json_build_object('name', 'posts', 'value', sum(posts)),
json_build_object('name', 'comments', 'value', sum(comments)),
json_build_object('name', 'jobs', 'value', sum(jobs))
) AS data
FROM item_growth_days
WHERE ${viewIntervalClause(when, 'item_growth_days', false)}
GROUP BY time
ORDER BY time ASC`)
}
return await models.$queryRaw(
`${withClause(when)}
SELECT time, json_build_array(
@ -103,6 +152,21 @@ export default {
ORDER BY time ASC`)
},
spendingGrowth: async (parent, { when }, { models }) => {
if (when !== 'day') {
return await models.$queryRaw(`
SELECT date_trunc('${timeUnit(when)}', day) as time, json_build_array(
json_build_object('name', 'jobs', 'value', sum(jobs)),
json_build_object('name', 'boost', 'value', sum(boost)),
json_build_object('name', 'fees', 'value', sum(fees)),
json_build_object('name', 'tips', 'value', sum(tips)),
json_build_object('name', 'donations', 'value', sum(donations))
) AS data
FROM spending_growth_days
WHERE ${viewIntervalClause(when, 'spending_growth_days', false)}
GROUP BY time
ORDER BY time ASC`)
}
return await models.$queryRaw(
`${withClause(when)}
SELECT time, json_build_array(
@ -125,6 +189,21 @@ export default {
ORDER BY time ASC`)
},
stackerGrowth: async (parent, { when }, { models }) => {
if (when !== 'day') {
return await models.$queryRaw(`
SELECT date_trunc('${timeUnit(when)}', day) as time, json_build_array(
json_build_object('name', 'any', 'value', sum("any")),
json_build_object('name', 'posts', 'value', sum(posts)),
json_build_object('name', 'comments', 'value', sum(comments)),
json_build_object('name', 'rewards', 'value', sum(rewards)),
json_build_object('name', 'referrals', 'value', sum(referrals))
) AS data
FROM stackers_growth_days
WHERE ${viewIntervalClause(when, 'stackers_growth_days', false)}
GROUP BY time
ORDER BY time ASC`)
}
return await models.$queryRaw(
`${withClause(when)}
SELECT time, json_build_array(
@ -152,6 +231,20 @@ export default {
ORDER BY time ASC`)
},
stackingGrowth: async (parent, { when }, { models }) => {
if (when !== 'day') {
return await models.$queryRaw(`
SELECT date_trunc('${timeUnit(when)}', day) as time, json_build_array(
json_build_object('name', 'rewards', 'value', sum(rewards)),
json_build_object('name', 'posts', 'value', sum(posts)),
json_build_object('name', 'comments', 'value', sum(comments)),
json_build_object('name', 'referrals', 'value', sum(referrals))
) AS data
FROM stacking_growth_days
WHERE ${viewIntervalClause(when, 'stacking_growth_days', false)}
GROUP BY time
ORDER BY time ASC`)
}
return await models.$queryRaw(
`${withClause(when)}
SELECT time, json_build_array(

View File

@ -7,7 +7,7 @@ import notifications from './notifications'
import invite from './invite'
import sub from './sub'
import upload from './upload'
// import growth from './growth'
import growth from './growth'
import search from './search'
import rewards from './rewards'
import referrals from './referrals'
@ -15,4 +15,4 @@ import price from './price'
import { GraphQLJSONObject } from 'graphql-type-json'
export default [user, item, message, wallet, lnurl, notifications, invite, sub,
upload, search, rewards, referrals, price, { JSONObject: GraphQLJSONObject }]
upload, search, growth, rewards, referrals, price, { JSONObject: GraphQLJSONObject }]

View File

@ -1,20 +1,20 @@
import { gql } from 'apollo-server-micro'
// extend type Query {
// registrationGrowth(when: String): [TimeData!]!
// itemGrowth(when: String): [TimeData!]!
// spendingGrowth(when: String): [TimeData!]!
// spenderGrowth(when: String): [TimeData!]!
// stackingGrowth(when: String): [TimeData!]!
// stackerGrowth(when: String): [TimeData!]!
// }
export default gql`
type NameValue {
name: String!
value: Int!
}
extend type Query {
registrationGrowth(when: String): [TimeData!]!
itemGrowth(when: String): [TimeData!]!
spendingGrowth(when: String): [TimeData!]!
spenderGrowth(when: String): [TimeData!]!
stackingGrowth(when: String): [TimeData!]!
stackerGrowth(when: String): [TimeData!]!
}
type TimeData {
time: String!
data: [NameValue!]!

94
pages/users/[when].js Normal file
View File

@ -0,0 +1,94 @@
import { gql } from '@apollo/client'
import { getGetServerSideProps } from '../../api/ssrApollo'
import Layout from '../../components/layout'
import { Col, Row } from 'react-bootstrap'
import { UsageHeader } from '../../components/usage-header'
import { WhenLineChart, WhenAreaChart } from '../../components/when-charts'
export const getServerSideProps = getGetServerSideProps(
gql`
query Growth($when: String!)
{
registrationGrowth(when: $when) {
time
data {
name
value
}
}
itemGrowth(when: $when) {
time
data {
name
value
}
}
spendingGrowth(when: $when) {
time
data {
name
value
}
}
spenderGrowth(when: $when) {
time
data {
name
value
}
}
stackingGrowth(when: $when) {
time
data {
name
value
}
}
stackerGrowth(when: $when) {
time
data {
name
value
}
}
}`)
export default function Growth ({
data: { registrationGrowth, itemGrowth, spendingGrowth, spenderGrowth, stackingGrowth, stackerGrowth }
}) {
return (
<Layout>
<UsageHeader />
<Row>
<Col className='mt-3'>
<div className='text-center text-muted font-weight-bold'>stackers</div>
<WhenLineChart data={stackerGrowth} />
</Col>
<Col className='mt-3'>
<div className='text-center text-muted font-weight-bold'>stacking</div>
<WhenAreaChart data={stackingGrowth} />
</Col>
</Row>
<Row>
<Col className='mt-3'>
<div className='text-center text-muted font-weight-bold'>spenders</div>
<WhenLineChart data={spenderGrowth} />
</Col>
<Col className='mt-3'>
<div className='text-center text-muted font-weight-bold'>spending</div>
<WhenAreaChart data={spendingGrowth} />
</Col>
</Row>
<Row>
<Col className='mt-3'>
<div className='text-center text-muted font-weight-bold'>registrations</div>
<WhenAreaChart data={registrationGrowth} />
</Col>
<Col className='mt-3'>
<div className='text-center text-muted font-weight-bold'>items</div>
<WhenAreaChart data={itemGrowth} />
</Col>
</Row>
</Layout>
)
}

16
pages/users/search.js Normal file
View File

@ -0,0 +1,16 @@
import Layout from '../../components/layout'
import { getGetServerSideProps } from '../../api/ssrApollo'
import { SeoSearch } from '../../components/seo'
import { USER_SEARCH } from '../../fragments/users'
import UserList from '../../components/user-list'
export const getServerSideProps = getGetServerSideProps(USER_SEARCH, { limit: 21, similarity: 0.2 })
export default function Index ({ data: { searchUsers } }) {
return (
<Layout noSeo search>
<SeoSearch />
<UserList users={searchUsers} />
</Layout>
)
}

View File

@ -0,0 +1,112 @@
-- the idea is that we refresh these every day after midnight texas time
-- then anything but days doesn't need to be compute from scatch
-- all days since the beginning of founding
CREATE OR REPLACE VIEW days AS
WITH range_values AS (
SELECT date_trunc('day', '2021-06-07'::timestamp) as minval,
date_trunc('day', timezone('America/Chicago', now() - interval '1 day')) as maxval)
SELECT generate_series(minval, maxval, interval '1 day') as day
FROM range_values;
-- get registrations
CREATE MATERIALIZED VIEW IF NOT EXISTS reg_growth_days AS
SELECT day, count("referrerId") as referrals,
count(users.id) FILTER(WHERE id > 616) - count("inviteId") as organic
FROM days
LEFT JOIN users ON day = date_trunc('day', timezone('America/Chicago', created_at at time zone 'UTC'))
GROUP BY day
ORDER BY day ASC;
-- get spenders
CREATE MATERIALIZED VIEW IF NOT EXISTS spender_growth_days AS
SELECT day, count(DISTINCT "userId") as any,
count(DISTINCT "userId") FILTER (WHERE act = 'STREAM') as jobs,
count(DISTINCT "userId") FILTER (WHERE act = 'BOOST') as boost,
count(DISTINCT "userId") FILTER (WHERE act = 'FEE') as fees,
count(DISTINCT "userId") FILTER (WHERE act = 'TIP') as tips,
count(DISTINCT "userId") FILTER (WHERE act = 'DONATION') as donations
FROM days
LEFT JOIN
((SELECT "ItemAct".created_at, "userId", act::text as act
FROM "ItemAct")
UNION ALL
(SELECT created_at, "userId", 'DONATION' as act
FROM "Donation")) u ON day = date_trunc('day', timezone('America/Chicago', u.created_at at time zone 'UTC'))
GROUP BY day
ORDER BY day ASC;
-- get items
CREATE MATERIALIZED VIEW IF NOT EXISTS item_growth_days AS
SELECT day, count("parentId") as comments,
count("subName") FILTER (WHERE "subName" = 'jobs') as jobs,
count(id) FILTER (WHERE "parentId" IS NULL AND "subName" <> 'jobs') as posts
FROM days
LEFT JOIN "Item" ON day = date_trunc('day', timezone('America/Chicago', created_at at time zone 'UTC'))
GROUP BY day
ORDER BY day ASC;
-- get spending
CREATE MATERIALIZED VIEW IF NOT EXISTS spending_growth_days AS
SELECT day, coalesce(floor(sum(msats) FILTER (WHERE act = 'STREAM')/1000), 0) as jobs,
coalesce(floor(sum(msats) FILTER (WHERE act = 'BOOST')/1000), 0) as boost,
coalesce(floor(sum(msats) FILTER (WHERE act NOT IN ('BOOST', 'TIP', 'STREAM', 'DONATION'))/1000), 0) as fees,
coalesce(floor(sum(msats) FILTER (WHERE act = 'TIP')/1000), 0) as tips,
coalesce(floor(sum(msats) FILTER (WHERE act = 'DONATION')/1000), 0) as donations
FROM days
LEFT JOIN
((SELECT "ItemAct".created_at, msats, act::text as act
FROM "ItemAct")
UNION ALL
(SELECT created_at, sats * 1000 as msats, 'DONATION' as act
FROM "Donation")) u ON day = date_trunc('day', timezone('America/Chicago', u.created_at at time zone 'UTC'))
GROUP BY day
ORDER BY day ASC;
-- get stackers
CREATE MATERIALIZED VIEW IF NOT EXISTS stackers_growth_days AS
SELECT day, count(distinct user_id) as any,
count(distinct user_id) FILTER (WHERE type = 'POST') as posts,
count(distinct user_id) FILTER (WHERE type = 'COMMENT') as comments,
count(distinct user_id) FILTER (WHERE type = 'EARN') as rewards,
count(distinct user_id) FILTER (WHERE type = 'REFERRAL') as referrals
FROM days
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 "ItemAct".act = 'TIP')
UNION ALL
(SELECT created_at, "userId" as user_id, 'EARN' as type
FROM "Earn")
UNION ALL
(SELECT created_at, "referrerId" as user_id, 'REFERRAL' as type
FROM "ReferralAct")) u ON day = date_trunc('day', timezone('America/Chicago', u.created_at at time zone 'UTC'))
GROUP BY day
ORDER BY day ASC;
-- get stacking
CREATE MATERIALIZED VIEW IF NOT EXISTS stacking_growth_days AS
SELECT day, coalesce(floor(sum(airdrop)/1000),0) as rewards,
coalesce(floor(sum(post)/1000),0) as posts,
coalesce(floor(sum(comment)/1000),0) as comments,
coalesce(floor(sum(referral)/1000),0) as referrals
FROM days
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
FROM "ItemAct"
JOIN "Item" on "ItemAct"."itemId" = "Item".id
WHERE "ItemAct".act = 'TIP')
UNION ALL
(SELECT created_at, 0 as airdrop, 0 as post, 0 as comment, msats as referral
FROM "ReferralAct")
UNION ALL
(SELECT created_at, msats as airdrop, 0 as post, 0 as comment, 0 as referral
FROM "Earn")) u ON day = date_trunc('day', timezone('America/Chicago', u.created_at at time zone 'UTC'))
GROUP BY day
ORDER BY day ASC;

View File

@ -15,6 +15,7 @@ const { nip57 } = require('./nostr')
const fetch = require('cross-fetch')
const { authenticatedLndGrpc } = require('ln-service')
const { views } = require('./views')
async function work () {
const boss = new PgBoss(process.env.DATABASE_URL)
@ -60,6 +61,7 @@ async function work () {
await boss.work('streak', computeStreaks(args))
await boss.work('checkStreak', checkStreak(args))
await boss.work('nip57', nip57(args))
await boss.work('views', views(args))
console.log('working jobs')
}

14
worker/views.js Normal file
View File

@ -0,0 +1,14 @@
function views ({ models }) {
return async function () {
console.log('refreshing views')
for (const view of ['reg_growth_days', 'spender_growth_days', 'item_growth_days',
'spending_growth_days', 'stackers_growth_days', 'stacking_growth_days']) {
await models.$queryRaw(`REFRESH MATERIALIZED VIEW ${view}`)
}
console.log('done refreshing views')
}
}
module.exports = { views }