umami/queries/analytics/reports/getFunnel.ts

201 lines
5.1 KiB
TypeScript
Raw Normal View History

2023-05-09 08:46:58 +02:00
import clickhouse from 'lib/clickhouse';
import { CLICKHOUSE, PRISMA, runQuery } from 'lib/db';
import prisma from 'lib/prisma';
export async function getFunnel(
2023-05-09 08:46:58 +02:00
...args: [
websiteId: string,
criteria: {
windowMinutes: number;
startDate: Date;
endDate: Date;
urls: string[];
},
]
) {
return runQuery({
[PRISMA]: () => relationalQuery(...args),
[CLICKHOUSE]: () => clickhouseQuery(...args),
});
}
async function relationalQuery(
websiteId: string,
criteria: {
windowMinutes: number;
startDate: Date;
endDate: Date;
urls: string[];
},
2023-05-12 01:42:58 +02:00
): Promise<
{
2023-05-18 20:17:35 +02:00
x: string;
y: number;
z: number;
2023-05-12 01:42:58 +02:00
}[]
> {
2023-05-09 08:46:58 +02:00
const { windowMinutes, startDate, endDate, urls } = criteria;
2023-07-28 19:47:14 +02:00
const { rawQuery, getAddMinutesQuery } = prisma;
const { levelQuery, sumQuery } = getFunnelQuery(urls, windowMinutes);
function getFunnelQuery(
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: '',
},
);
}
2023-05-09 08:46:58 +02:00
return rawQuery(
2023-07-25 22:23:44 +02:00
`WITH level1 AS (
select distinct session_id, created_at
2023-05-12 01:42:58 +02:00
from website_event
2023-07-28 19:47:14 +02:00
where website_id = {{websiteId::uuid}}
2023-07-28 00:23:20 +02:00
and created_at between {{startDate}} and {{endDate}}
and url_path = {{0}})
2023-07-25 22:23:44 +02:00
${levelQuery}
2023-07-24 20:57:46 +02:00
${sumQuery}
ORDER BY level;`,
2023-07-28 19:47:14 +02:00
{
websiteId,
startDate,
endDate,
...urls,
},
).then(results => {
return urls.map((a, i) => ({
x: a,
y: results[i]?.count || 0,
2023-07-24 20:57:46 +02:00
z: (1 - (Number(results[i]?.count) * 1.0) / Number(results[i - 1]?.count)) * 100 || 0, // drop off
}));
2023-05-12 01:42:58 +02:00
});
2023-05-09 08:46:58 +02:00
}
async function clickhouseQuery(
websiteId: string,
criteria: {
windowMinutes: number;
startDate: Date;
endDate: Date;
urls: string[];
},
2023-05-12 01:42:58 +02:00
): Promise<
{
2023-05-18 20:17:35 +02:00
x: string;
y: number;
2023-07-25 22:23:44 +02:00
z: number;
2023-05-12 01:42:58 +02:00
}[]
> {
2023-05-09 08:46:58 +02:00
const { windowMinutes, startDate, endDate, urls } = criteria;
2023-07-28 19:47:14 +02:00
const { rawQuery } = clickhouse;
2023-07-25 22:23:44 +02:00
const { levelQuery, sumQuery, urlFilterQuery, urlParams } = getFunnelQuery(urls, windowMinutes);
2023-05-09 08:46:58 +02:00
2023-07-28 19:47:14 +02:00
function getFunnelQuery(
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: {},
},
);
}
2023-05-09 08:46:58 +02:00
2023-05-12 01:42:58 +02:00
return rawQuery<{ level: number; count: number }[]>(
2023-05-09 08:46:58 +02:00
`
2023-07-25 22:23:44 +02:00
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}
2023-07-25 22:23:44 +02:00
), level1 AS (
select *
from level0
where url_path = {url0:String})
${levelQuery}
select *
2023-07-21 06:13:29 +02:00
from (
2023-07-25 22:23:44 +02:00
${sumQuery}
) ORDER BY level;`,
2023-07-28 19:47:14 +02:00
{
websiteId,
startDate,
endDate,
...urlParams,
},
2023-05-15 23:03:42 +02:00
).then(results => {
return urls.map((a, i) => ({
2023-05-18 20:17:35 +02:00
x: a,
2023-07-24 20:57:46 +02:00
y: results[i]?.count || 0,
z: (1 - (Number(results[i]?.count) * 1.0) / Number(results[i - 1]?.count)) * 100 || 0, // drop off
2023-05-15 23:03:42 +02:00
}));
2023-05-12 01:42:58 +02:00
});
2023-05-09 08:46:58 +02:00
}