Merge pull request #2149 from umami-software/bug/um-362-relational-funnels-query

Bug/um 362 relational funnels query
This commit is contained in:
Mike Cao 2023-07-28 18:20:26 -07:00 committed by GitHub
commit 200e9b8bfa
No known key found for this signature in database
GPG key ID: 4AEE18F83AFDEB23
5 changed files with 132 additions and 118 deletions

View file

@ -31,31 +31,74 @@ async function relationalQuery(
{
x: string;
y: number;
z: number;
}[]
> {
const { windowMinutes, startDate, endDate, urls } = criteria;
const { rawQuery, getFunnelQuery } = prisma;
const { levelQuery, sumQuery, urlFilterQuery } = getFunnelQuery(urls, windowMinutes);
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: '',
},
);
}
return rawQuery(
`WITH level0 AS (
select distinct session_id, url_path, referrer_path, created_at
`WITH level1 AS (
select distinct session_id, created_at
from website_event
where url_path in (${urlFilterQuery})
and website_id = {{websiteId::uuid}}
and created_at between {{startDate}} and {{endDate}}
),level1 AS (
select distinct session_id, url_path as level_1_url, created_at as level_1_created_at
from level0
where url_path = $4
)${levelQuery}
SELECT ${sumQuery}
from level${urls.length};
`,
{ websiteId, startDate, endDate, ...urls },
).then((a: { [key: string]: number }) => {
return urls.map((b, i) => ({ x: b, y: a[0][`level${i + 1}`] || 0 }));
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) * 1.0) / Number(results[i - 1]?.count)) * 100 || 0, // drop off
}));
});
}
@ -71,42 +114,87 @@ async function clickhouseQuery(
{
x: string;
y: number;
z: number;
}[]
> {
const { windowMinutes, startDate, endDate, urls } = criteria;
const { rawQuery, getFunnelQuery } = clickhouse;
const { columnsQuery, urlParams } = getFunnelQuery(urls);
const { rawQuery } = clickhouse;
const { levelQuery, sumQuery, urlFilterQuery, urlParams } = getFunnelQuery(urls, windowMinutes);
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: {},
},
);
}
return rawQuery<{ level: number; count: number }[]>(
`
SELECT level,
count(*) AS count
FROM (
SELECT session_id,
windowFunnel({window:UInt32}, 'strict_increase')
(
created_at
${columnsQuery}
) AS level
FROM website_event
WHERE website_id = {websiteId:UUID}
AND created_at BETWEEN {startDate:DateTime} AND {endDate:DateTime}
GROUP BY 1
)
GROUP BY level
ORDER BY level ASC;
`,
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,
window: windowMinutes * 60,
...urlParams,
},
).then(results => {
return urls.map((a, i) => ({
x: a,
y: results[i + 1]?.count || 0,
y: results[i]?.count || 0,
z: (1 - (Number(results[i]?.count) * 1.0) / Number(results[i - 1]?.count)) * 100 || 0, // drop off
}));
});
}