From 13530c9cdcf38289c80cc42563b05cb92dcf53ea Mon Sep 17 00:00:00 2001 From: Francis Cao Date: Mon, 7 Aug 2023 14:01:53 -0700 Subject: [PATCH] add psql query for retention --- .../reports/retention/RetentionParameters.js | 14 +- .../reports/retention/RetentionReport.js | 6 +- .../pages/reports/retention/RetentionTable.js | 25 +- pages/api/reports/retention.ts | 15 +- queries/analytics/reports/getRetention.ts | 328 +++++++++--------- 5 files changed, 193 insertions(+), 195 deletions(-) diff --git a/components/pages/reports/retention/RetentionParameters.js b/components/pages/reports/retention/RetentionParameters.js index 29c0eff2..bf40236d 100644 --- a/components/pages/reports/retention/RetentionParameters.js +++ b/components/pages/reports/retention/RetentionParameters.js @@ -4,6 +4,11 @@ import { Form, FormButtons, FormInput, FormRow, SubmitButton, TextField } from ' import { ReportContext } from 'components/pages/reports/Report'; import BaseParameters from '../BaseParameters'; +const fieldOptions = [ + { name: 'daily', type: 'string' }, + { name: 'weekly', type: 'string' }, +]; + export function RetentionParameters() { const { report, runReport, isRunning } = useContext(ReportContext); const { formatMessage, labels } = useMessages(); @@ -24,14 +29,7 @@ export function RetentionParameters() { return (
- - - - - + {formatMessage(labels.runQuery)} diff --git a/components/pages/reports/retention/RetentionReport.js b/components/pages/reports/retention/RetentionReport.js index 31d085f7..cab3c16c 100644 --- a/components/pages/reports/retention/RetentionReport.js +++ b/components/pages/reports/retention/RetentionReport.js @@ -8,8 +8,8 @@ import ReportBody from '../ReportBody'; import Funnel from 'assets/funnel.svg'; const defaultParameters = { - type: 'Retention', - parameters: { window: 60, urls: [] }, + type: 'retention', + parameters: {}, }; export default function RetentionReport({ reportId }) { @@ -20,7 +20,7 @@ export default function RetentionReport({ reportId }) { - + {/* */} diff --git a/components/pages/reports/retention/RetentionTable.js b/components/pages/reports/retention/RetentionTable.js index 4ef87986..53db7841 100644 --- a/components/pages/reports/retention/RetentionTable.js +++ b/components/pages/reports/retention/RetentionTable.js @@ -1,18 +1,29 @@ import { useContext } from 'react'; -import DataTable from 'components/metrics/DataTable'; +import { GridTable, GridColumn } from 'react-basics'; import { useMessages } from 'hooks'; import { ReportContext } from '../Report'; export function RetentionTable() { const { report } = useContext(ReportContext); const { formatMessage, labels } = useMessages(); + const { fields = [] } = report?.parameters || {}; + + // return ( + // + // {fields.map(({ name }) => { + // return ; + // })} + // + // + // ); return ( - + + {row => row.cohortDate} + {row => row.date_number} + + {row => row.date_number} + + ); } diff --git a/pages/api/reports/retention.ts b/pages/api/reports/retention.ts index 6b8aebcc..0e2c71b8 100644 --- a/pages/api/reports/retention.ts +++ b/pages/api/reports/retention.ts @@ -7,17 +7,12 @@ import { getRetention } from 'queries'; export interface RetentionRequestBody { websiteId: string; - urls: string[]; - window: number; - dateRange: { - startDate: string; - endDate: string; - }; + window: string; + dateRange: { window; startDate: string; endDate: string }; } export interface RetentionResponse { - urls: string[]; - window: number; + window: string; startAt: number; endAt: number; } @@ -32,7 +27,6 @@ export default async ( if (req.method === 'POST') { const { websiteId, - urls, window, dateRange: { startDate, endDate }, } = req.body; @@ -44,8 +38,7 @@ export default async ( const data = await getRetention(websiteId, { startDate: new Date(startDate), endDate: new Date(endDate), - urls, - windowMinutes: +window, + window: window, }); return ok(res, data); diff --git a/queries/analytics/reports/getRetention.ts b/queries/analytics/reports/getRetention.ts index b2c47882..68d3b4b2 100644 --- a/queries/analytics/reports/getRetention.ts +++ b/queries/analytics/reports/getRetention.ts @@ -6,204 +6,200 @@ export async function getRetention( ...args: [ websiteId: string, criteria: { - windowMinutes: number; + window: string; startDate: Date; endDate: Date; - urls: string[]; }, ] ) { return runQuery({ [PRISMA]: () => relationalQuery(...args), - [CLICKHOUSE]: () => clickhouseQuery(...args), + // [CLICKHOUSE]: () => clickhouseQuery(...args), }); } async function relationalQuery( websiteId: string, criteria: { - windowMinutes: number; + window: string; startDate: Date; endDate: Date; - urls: string[]; }, ): Promise< { - x: string; - y: number; - z: number; + date: Date; + visitors: number; + day: number; + percentage: number; }[] > { - const { windowMinutes, startDate, endDate, urls } = criteria; - const { rawQuery, getAddMinutesQuery } = prisma; - const { levelQuery, sumQuery } = getRetentionQuery(urls, windowMinutes); - - function getRetentionQuery( - urls: string[], - windowMinutes: number, - ): { - levelQuery: string; - sumQuery: string; - } { - return urls.reduce( - (pv, cv, i) => { - const levelNumber = i + 1; - const startSum = i > 0 ? 'union ' : ''; - - if (levelNumber >= 2) { - pv.levelQuery += ` - , level${levelNumber} AS ( - select distinct we.session_id, we.created_at - from level${i} l - join website_event we - on l.session_id = we.session_id - where we.created_at between l.created_at - and ${getAddMinutesQuery(`l.created_at `, windowMinutes)} - and we.referrer_path = {{${i - 1}}} - and we.url_path = {{${i}}} - and we.created_at <= {{endDate}} - and we.website_id = {{websiteId::uuid}} - )`; - } - - pv.sumQuery += `\n${startSum}select ${levelNumber} as level, count(distinct(session_id)) as count from level${levelNumber}`; - - return pv; - }, - { - levelQuery: '', - sumQuery: '', - }, - ); - } + const { window, startDate, endDate } = criteria; + const { rawQuery } = prisma; return rawQuery( ` - WITH level1 AS ( - select distinct session_id, created_at - from website_event + WITH cohort_items AS ( + select + date_trunc('week', created_at)::date as cohort_date, + session_id + from session where website_id = {{websiteId::uuid}} and created_at between {{startDate}} and {{endDate}} - and url_path = {{0}} - ) - ${levelQuery} - ${sumQuery} - ORDER BY level; - `, - { - websiteId, - startDate, - endDate, - ...urls, - }, - ).then(results => { - return urls.map((a, i) => ({ - x: a, - y: results[i]?.count || 0, - z: (1 - Number(results[i]?.count) / Number(results[i - 1]?.count)) * 100 || 0, // drop off - })); - }); -} - -async function clickhouseQuery( - websiteId: string, - criteria: { - windowMinutes: number; - startDate: Date; - endDate: Date; - urls: string[]; - }, -): Promise< - { - x: string; - y: number; - z: number; - }[] -> { - const { windowMinutes, startDate, endDate, urls } = criteria; - const { rawQuery } = clickhouse; - const { levelQuery, sumQuery, urlFilterQuery, urlParams } = getRetentionQuery( - urls, - windowMinutes, - ); - - function getRetentionQuery( - urls: string[], - windowMinutes: number, - ): { - levelQuery: string; - sumQuery: string; - urlFilterQuery: string; - urlParams: { [key: string]: string }; - } { - return urls.reduce( - (pv, cv, i) => { - const levelNumber = i + 1; - const startSum = i > 0 ? 'union all ' : ''; - const startFilter = i > 0 ? ', ' : ''; - - if (levelNumber >= 2) { - pv.levelQuery += `\n - , level${levelNumber} AS ( - select distinct y.session_id as session_id, - y.url_path as url_path, - y.referrer_path as referrer_path, - y.created_at as created_at - from level${i} x - join level0 y - on x.session_id = y.session_id - where y.created_at between x.created_at and x.created_at + interval ${windowMinutes} minute - and y.referrer_path = {url${i - 1}:String} - and y.url_path = {url${i}:String} - )`; - } - - pv.sumQuery += `\n${startSum}select ${levelNumber} as level, count(distinct(session_id)) as count from level${levelNumber}`; - pv.urlFilterQuery += `${startFilter}{url${i}:String} `; - pv.urlParams[`url${i}`] = cv; - - return pv; - }, - { - levelQuery: '', - sumQuery: '', - urlFilterQuery: '', - urlParams: {}, - }, - ); - } - - return rawQuery<{ level: number; count: number }[]>( - ` - WITH level0 AS ( - select distinct session_id, url_path, referrer_path, created_at - from umami.website_event - where url_path in (${urlFilterQuery}) - and website_id = {websiteId:UUID} - and created_at between {startDate:DateTime64} and {endDate:DateTime64} + order by 1, 2 ), - level1 AS ( - select * - from level0 - where url_path = {url0:String} + user_activities AS ( + select distinct + w.session_id, + (date_trunc('week', w.created_at)::date - c.cohort_date::date) / 7 as date_number + from website_event w + left join cohort_items c + on w.session_id = c.session_id + where website_id = {{websiteId::uuid}} + and created_at between {{startDate}} and {{endDate}} + ), + cohort_size as ( + select cohort_date, + count(*) as visitors + from cohort_items + group by 1 + order by 1 + ), + cohort_date as ( + select + c.cohort_date, + a.date_number, + count(*) as visitors + from user_activities a + left join cohort_items c + on a.session_id = c.session_id + group by 1, 2 ) - ${levelQuery} - select * - from ( - ${sumQuery} - ) ORDER BY level; - `, + select + c.cohort_date, + c.date_number, + s.visitors, + c.visitors, + c.visitors::float * 100 / s.visitors as percentage + from cohort_date c + left join cohort_size s + on c.cohort_date = s.cohort_date + where c.cohort_date IS NOT NULL + order by 1, 2`, { websiteId, startDate, endDate, - ...urlParams, + window, }, ).then(results => { - return urls.map((a, i) => ({ - x: a, - y: results[i]?.count || 0, - z: (1 - Number(results[i]?.count) / Number(results[i - 1]?.count)) * 100 || 0, // drop off - })); + return results; + // return results.map((a, i) => ({ + // x: a, + // y: results[i]?.count || 0, + // z: (1 - Number(results[i]?.count) / Number(results[i - 1]?.count)) * 100 || 0, // drop off + // })); }); } + +// async function clickhouseQuery( +// websiteId: string, +// criteria: { +// windowMinutes: number; +// startDate: Date; +// endDate: Date; +// urls: string[]; +// }, +// ): Promise< +// { +// x: string; +// y: number; +// z: number; +// }[] +// > { +// const { windowMinutes, startDate, endDate, urls } = criteria; +// const { rawQuery } = clickhouse; +// const { levelQuery, sumQuery, urlFilterQuery, urlParams } = getRetentionQuery( +// urls, +// windowMinutes, +// ); + +// function getRetentionQuery( +// urls: string[], +// windowMinutes: number, +// ): { +// levelQuery: string; +// sumQuery: string; +// urlFilterQuery: string; +// urlParams: { [key: string]: string }; +// } { +// return urls.reduce( +// (pv, cv, i) => { +// const levelNumber = i + 1; +// const startSum = i > 0 ? 'union all ' : ''; +// const startFilter = i > 0 ? ', ' : ''; + +// if (levelNumber >= 2) { +// pv.levelQuery += `\n +// , level${levelNumber} AS ( +// select distinct y.session_id as session_id, +// y.url_path as url_path, +// y.referrer_path as referrer_path, +// y.created_at as created_at +// from level${i} x +// join level0 y +// on x.session_id = y.session_id +// where y.created_at between x.created_at and x.created_at + interval ${windowMinutes} minute +// and y.referrer_path = {url${i - 1}:String} +// and y.url_path = {url${i}:String} +// )`; +// } + +// pv.sumQuery += `\n${startSum}select ${levelNumber} as level, count(distinct(session_id)) as count from level${levelNumber}`; +// pv.urlFilterQuery += `${startFilter}{url${i}:String} `; +// pv.urlParams[`url${i}`] = cv; + +// return pv; +// }, +// { +// levelQuery: '', +// sumQuery: '', +// urlFilterQuery: '', +// urlParams: {}, +// }, +// ); +// } + +// return rawQuery<{ level: number; count: number }[]>( +// ` +// WITH level0 AS ( +// select distinct session_id, url_path, referrer_path, created_at +// from umami.website_event +// where url_path in (${urlFilterQuery}) +// and website_id = {websiteId:UUID} +// and created_at between {startDate:DateTime64} and {endDate:DateTime64} +// ), +// level1 AS ( +// select * +// from level0 +// where url_path = {url0:String} +// ) +// ${levelQuery} +// select * +// from ( +// ${sumQuery} +// ) ORDER BY level; +// `, +// { +// websiteId, +// startDate, +// endDate, +// ...urlParams, +// }, +// ).then(results => { +// return urls.map((a, i) => ({ +// x: a, +// y: results[i]?.count || 0, +// z: (1 - Number(results[i]?.count) / Number(results[i - 1]?.count)) * 100 || 0, // drop off +// })); +// }); +// }