update funnels relational query

This commit is contained in:
Francis Cao 2023-07-20 21:13:29 -07:00
parent 25feee662b
commit 94967d45e1
2 changed files with 46 additions and 31 deletions

View file

@ -44,6 +44,18 @@ function getAddMinutesQuery(field: string, minutes: number) {
}
}
function getDropoffQuery() {
const db = getDatabaseType(process.env.DATABASE_URL);
if (db === POSTGRESQL) {
return `round((1.0 - count::numeric/lag(count, 1) over ()),2)`;
}
if (db === MYSQL) {
return `round((1.0 - count/LAG(count, 1) OVER (ORDER BY level)),2)`;
}
}
function getDateQuery(field: string, unit: string, timezone?: string): string {
const db = getDatabaseType(process.env.DATABASE_URL);
@ -147,29 +159,27 @@ function getFunnelQuery(
return urls.reduce(
(pv, cv, i) => {
const levelNumber = i + 1;
const start = i > 0 ? ',' : '';
const startSum = i > 0 ? 'union ' : '';
const startFilter = i > 0 ? ', ' : '';
if (levelNumber >= 2) {
pv.levelQuery += `\n
, level${levelNumber} AS (
select cl.*,
l0.created_at level_${levelNumber}_created_at,
l0.url_path as level_${levelNumber}_url
from level${i} cl
left join website_event l0
on cl.session_id = l0.session_id
and l0.created_at between cl.level_${i}_created_at
and ${getAddMinutesQuery(`cl.level_${i}_created_at`, windowMinutes)}
and l0.referrer_path = $${i + initParamLength}
and l0.url_path = $${levelNumber + initParamLength}
and created_at between $2 and $3
and website_id = $1${toUuid()}
select distinct l.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 + initParamLength}
and we.url_path = $${levelNumber + initParamLength}
and we.website_id = $1${toUuid()}
)`;
}
pv.sumQuery += `\n${start}SUM(CASE WHEN level_${levelNumber}_url is not null THEN 1 ELSE 0 END) AS level${levelNumber}`;
pv.sumQuery += `\n${startSum}select ${levelNumber} as level, count(distinct(session_id)) as count from level${levelNumber}`;
pv.urlFilterQuery += `\n${start}$${levelNumber + initParamLength} `;
pv.urlFilterQuery += `${startFilter}$${levelNumber + initParamLength} `;
return pv;
},
@ -212,6 +222,7 @@ async function rawQuery(query: string, params: never[] = []): Promise<any> {
export default {
...prisma,
getAddMinutesQuery,
getDropoffQuery,
getDateQuery,
getTimestampInterval,
getFilterQuery,

View file

@ -34,7 +34,7 @@ async function relationalQuery(
}[]
> {
const { windowMinutes, startDate, endDate, urls } = criteria;
const { rawQuery, getFunnelQuery, toUuid } = prisma;
const { rawQuery, getFunnelQuery, toUuid, getDropoffQuery } = prisma;
const { levelQuery, sumQuery, urlFilterQuery } = getFunnelQuery(urls, windowMinutes);
const params: any = [websiteId, startDate, endDate, ...urls];
@ -47,14 +47,18 @@ async function relationalQuery(
and website_id = $1${toUuid()}
and created_at between $2 and $3
),level1 AS (
select distinct session_id, url_path as level_1_url, created_at as level_1_created_at
select distinct session_id, created_at
from level0
where url_path = $4
)${levelQuery}
SELECT ${sumQuery}
from level${urls.length};
`,
)${levelQuery}, levelCount as (
${sumQuery}
order by level)
select
level,
count,
${getDropoffQuery()} as drop_off
from levelCount;
`,
params,
).then((a: { [key: string]: number }) => {
return urls.map((b, i) => ({ x: b, y: a[0][`level${i + 1}`] || 0 }));
@ -77,7 +81,7 @@ async function clickhouseQuery(
> {
const { windowMinutes, startDate, endDate, urls } = criteria;
const { rawQuery, getBetweenDates, getFunnelQuery } = clickhouse;
const { columnsQuery, conditionQuery, urlParams } = getFunnelQuery(urls);
const { columnsQuery, urlParams } = getFunnelQuery(urls);
const params = {
websiteId,
@ -87,22 +91,22 @@ async function clickhouseQuery(
return rawQuery<{ level: number; count: number }[]>(
`
SELECT level,
select level,
count(*) AS count
FROM (
SELECT session_id,
from (
select session_id,
windowFunnel({window:UInt32}, 'strict_increase')
(
created_at
${columnsQuery}
) AS level
FROM website_event
WHERE website_id = {websiteId:UUID}
from website_event
where website_id = {websiteId:UUID}
and ${getBetweenDates('created_at', startDate, endDate)}
GROUP BY 1
group by 1
)
GROUP BY level
ORDER BY level ASC;
group by level
order by level asc;
`,
params,
).then(results => {