mirror of
https://github.com/umami-software/umami.git
synced 2026-02-08 22:57:12 +01:00
Bootstrap User Journey report.
This commit is contained in:
parent
37eb157ab5
commit
76cab03bb2
18 changed files with 329 additions and 19 deletions
148
src/queries/analytics/reports/getJourney.ts
Normal file
148
src/queries/analytics/reports/getJourney.ts
Normal file
|
|
@ -0,0 +1,148 @@
|
|||
import clickhouse from 'lib/clickhouse';
|
||||
import { CLICKHOUSE, PRISMA, runQuery } from 'lib/db';
|
||||
import prisma from 'lib/prisma';
|
||||
|
||||
export async function getJourney(
|
||||
...args: [
|
||||
websiteId: string,
|
||||
filters: {
|
||||
startDate: Date;
|
||||
endDate: Date;
|
||||
},
|
||||
]
|
||||
) {
|
||||
return runQuery({
|
||||
[PRISMA]: () => relationalQuery(...args),
|
||||
[CLICKHOUSE]: () => clickhouseQuery(...args),
|
||||
});
|
||||
}
|
||||
|
||||
async function relationalQuery(
|
||||
websiteId: string,
|
||||
filters: {
|
||||
startDate: Date;
|
||||
endDate: Date;
|
||||
},
|
||||
): Promise<
|
||||
{
|
||||
e1: string;
|
||||
e2: string;
|
||||
e3: string;
|
||||
e4: string;
|
||||
e5: string;
|
||||
count: string;
|
||||
}[]
|
||||
> {
|
||||
const { startDate, endDate } = filters;
|
||||
const { rawQuery } = prisma;
|
||||
|
||||
return rawQuery(
|
||||
`
|
||||
WITH events AS (
|
||||
select distinct
|
||||
session_id,
|
||||
referrer_path,
|
||||
COALESCE(event_name, url_path) event,
|
||||
ROW_NUMBER() OVER (PARTITION BY session_id ORDER BY created_at) AS event_number
|
||||
from website_event
|
||||
where website_id = {{websiteId::uuid}}
|
||||
and created_at between {{startDate}} and {{endDate}}
|
||||
and referrer_path != url_path),
|
||||
sequences as (
|
||||
SELECT s.e1,
|
||||
s.e2,
|
||||
s.e3,
|
||||
s.e4,
|
||||
s.e5,
|
||||
count(*) count
|
||||
FROM (
|
||||
SELECT session_id,
|
||||
MAX(CASE WHEN event_number = 1 THEN event ELSE NULL END) AS e1,
|
||||
MAX(CASE WHEN event_number = 2 THEN event ELSE NULL END) AS e2,
|
||||
MAX(CASE WHEN event_number = 3 THEN event ELSE NULL END) AS e3,
|
||||
MAX(CASE WHEN event_number = 4 THEN event ELSE NULL END) AS e4,
|
||||
MAX(CASE WHEN event_number = 5 THEN event ELSE NULL END) AS e5
|
||||
FROM events
|
||||
group by session_id) s
|
||||
group by s.e1,
|
||||
s.e2,
|
||||
s.e3,
|
||||
s.e4,
|
||||
s.e5)
|
||||
select *
|
||||
from sequences
|
||||
order by count desc
|
||||
limit 100
|
||||
`,
|
||||
{
|
||||
websiteId,
|
||||
startDate,
|
||||
endDate,
|
||||
},
|
||||
);
|
||||
}
|
||||
|
||||
async function clickhouseQuery(
|
||||
websiteId: string,
|
||||
filters: {
|
||||
startDate: Date;
|
||||
endDate: Date;
|
||||
},
|
||||
): Promise<
|
||||
{
|
||||
e1: string;
|
||||
e2: string;
|
||||
e3: string;
|
||||
e4: string;
|
||||
e5: string;
|
||||
count: string;
|
||||
}[]
|
||||
> {
|
||||
const { startDate, endDate } = filters;
|
||||
const { rawQuery } = clickhouse;
|
||||
|
||||
return rawQuery(
|
||||
`
|
||||
WITH events AS (
|
||||
select distinct
|
||||
session_id,
|
||||
referrer_path,
|
||||
coalesce(nullIf(event_name, ''), url_path) event,
|
||||
row_number() OVER (PARTITION BY session_id ORDER BY created_at) AS event_number
|
||||
from umami.website_event
|
||||
where website_id = {websiteId:UUID}
|
||||
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
and referrer_path != url_path),
|
||||
sequences as (
|
||||
SELECT s.e1,
|
||||
s.e2,
|
||||
s.e3,
|
||||
s.e4,
|
||||
s.e5,
|
||||
count(*) count
|
||||
FROM (
|
||||
SELECT session_id,
|
||||
max(CASE WHEN event_number = 1 THEN event ELSE NULL END) AS e1,
|
||||
max(CASE WHEN event_number = 2 THEN event ELSE NULL END) AS e2,
|
||||
max(CASE WHEN event_number = 3 THEN event ELSE NULL END) AS e3,
|
||||
max(CASE WHEN event_number = 4 THEN event ELSE NULL END) AS e4,
|
||||
max(CASE WHEN event_number = 5 THEN event ELSE NULL END) AS e5
|
||||
FROM events
|
||||
group by session_id) s
|
||||
group by s.e1,
|
||||
s.e2,
|
||||
s.e3,
|
||||
s.e4,
|
||||
s.e5)
|
||||
select *
|
||||
from sequences
|
||||
order by count desc
|
||||
limit 100
|
||||
`,
|
||||
{
|
||||
websiteId,
|
||||
startDate,
|
||||
endDate,
|
||||
},
|
||||
);
|
||||
}
|
||||
|
|
@ -12,6 +12,7 @@ export * from './analytics/eventData/getEventDataStats';
|
|||
export * from './analytics/eventData/getEventDataUsage';
|
||||
export * from './analytics/events/saveEvent';
|
||||
export * from './analytics/reports/getFunnel';
|
||||
export * from './analytics/reports/getJourney';
|
||||
export * from './analytics/reports/getRetention';
|
||||
export * from './analytics/reports/getInsights';
|
||||
export * from './analytics/reports/getUTM';
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue