Skip to content
Open
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
1 change: 1 addition & 0 deletions docker-compose.yml
Original file line number Diff line number Diff line change
Expand Up @@ -8,6 +8,7 @@ services:
DATABASE_URL: postgresql://umami:umami@db:5432/umami
DATABASE_TYPE: postgresql
APP_SECRET: replace-me-with-a-random-string
# BOUNCE_THRESHOLD: 2 # OPTIONAL: set the minimum amount custom events to trigger a bounce
depends_on:
db:
condition: service_healthy
Expand Down
4 changes: 4 additions & 0 deletions src/lib/constants.ts
Original file line number Diff line number Diff line change
@@ -1,4 +1,8 @@
export const CURRENT_VERSION = process.env.currentVersion;
export const BOUNCE_THRESHOLD = Math.max(
1,
Number.parseInt(process.env.BOUNCE_THRESHOLD || '1', 10) || 1,
);
export const AUTH_TOKEN = 'umami.auth';
export const LOCALE_CONFIG = 'umami.locale';
export const TIMEZONE_CONFIG = 'umami.timezone';
Expand Down
9 changes: 5 additions & 4 deletions src/queries/sql/events/getWebsiteEvents.ts
Original file line number Diff line number Diff line change
@@ -1,5 +1,6 @@
import clickhouse from '@/lib/clickhouse';
import { CLICKHOUSE, getDatabaseType, POSTGRESQL, PRISMA, runQuery } from '@/lib/db';
import { EVENT_TYPE } from '@/lib/constants';
import prisma from '@/lib/prisma';
import { PageParams, QueryFilters } from '@/lib/types';

Expand Down Expand Up @@ -44,8 +45,8 @@ async function relationalQuery(websiteId: string, filters: QueryFilters, pagePar
${filterQuery}
${
search
? `and ((event_name ${like} {{search}} and event_type = 2)
or (url_path ${like} {{search}} and event_type = 1))`
? `and ((event_name ${like} {{search}} and event_type = ${EVENT_TYPE.customEvent})
or (url_path ${like} {{search}} and event_type = ${EVENT_TYPE.pageView}))`
: ''
}
order by created_at desc
Expand Down Expand Up @@ -82,8 +83,8 @@ async function clickhouseQuery(websiteId: string, filters: QueryFilters, pagePar
${filterQuery}
${
search
? `and ((positionCaseInsensitive(event_name, {search:String}) > 0 and event_type = 2)
or (positionCaseInsensitive(url_path, {search:String}) > 0 and event_type = 1))`
? `and ((positionCaseInsensitive(event_name, {search:String}) > 0 and event_type = ${EVENT_TYPE.customEvent})
or (positionCaseInsensitive(url_path, {search:String}) > 0 and event_type = ${EVENT_TYPE.pageView}))`
: ''
}
order by created_at desc
Expand Down
47 changes: 33 additions & 14 deletions src/queries/sql/getWebsiteStats.ts
Original file line number Diff line number Diff line change
@@ -1,9 +1,8 @@
import clickhouse from '@/lib/clickhouse';
import { EVENT_TYPE } from '@/lib/constants';
import { CLICKHOUSE, PRISMA, runQuery } from '@/lib/db';
import prisma from '@/lib/prisma';
import { QueryFilters } from '@/lib/types';
import { EVENT_COLUMNS } from '@/lib/constants';
import { BOUNCE_THRESHOLD, EVENT_COLUMNS, EVENT_TYPE } from '@/lib/constants';

export async function getWebsiteStats(
...args: [websiteId: string, filters: QueryFilters]
Expand Down Expand Up @@ -34,21 +33,28 @@ async function relationalQuery(
sum(t.c) as "pageviews",
count(distinct t.session_id) as "visitors",
count(distinct t.visit_id) as "visits",
sum(case when t.c = 1 then 1 else 0 end) as "bounces",
sum(case when t.c = 1 and t.events_count < ${BOUNCE_THRESHOLD} then 1 else 0 end) as "bounces",
sum(${getTimestampDiffSQL('t.min_time', 't.max_time')}) as "totaltime"
from (
select
website_event.session_id,
website_event.visit_id,
count(*) as "c",
sum(case when website_event.event_type = ${EVENT_TYPE.pageView} then 1 else 0 end) as "c",
min(website_event.created_at) as "min_time",
max(website_event.created_at) as "max_time"
max(website_event.created_at) as "max_time",
max((
select count(*)
from website_event we2
where we2.website_id = website_event.website_id
and we2.session_id = website_event.session_id
and we2.created_at between {{startDate}} and {{endDate}}
and we2.event_type = ${EVENT_TYPE.customEvent}
)) as "events_count"
from website_event
${cohortQuery}
${joinSession}
where website_event.website_id = {{websiteId::uuid}}
and website_event.created_at between {{startDate}} and {{endDate}}
and event_type = {{eventType}}
${filterQuery}
group by 1, 2
) as t
Expand Down Expand Up @@ -77,46 +83,59 @@ async function clickhouseQuery(
sum(t.c) as "pageviews",
uniq(t.session_id) as "visitors",
uniq(t.visit_id) as "visits",
sum(if(t.c = 1, 1, 0)) as "bounces",
sumIf(1, t.c = 1 and ifNull(e.events_count, 0) < ${BOUNCE_THRESHOLD}) as "bounces",
sum(max_time-min_time) as "totaltime"
from (
select
session_id,
visit_id,
count(*) c,
countIf(event_type = ${EVENT_TYPE.pageView}) as c,
min(created_at) min_time,
max(created_at) max_time
from website_event
${cohortQuery}
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and event_type = {eventType:UInt32}
${filterQuery}
group by session_id, visit_id
) as t;
) as t
left join (
select session_id, toUInt32(count()) as events_count
from website_event
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and event_type = ${EVENT_TYPE.customEvent}
group by session_id
) as e using session_id;
`;
} else {
sql = `
select
sum(t.c) as "pageviews",
uniq(session_id) as "visitors",
uniq(visit_id) as "visits",
sumIf(1, t.c = 1) as "bounces",
sumIf(1, t.c = 1 and ifNull(e.events_count, 0) < ${BOUNCE_THRESHOLD}) as "bounces",
sum(max_time-min_time) as "totaltime"
from (select
session_id,
visit_id,
sum(views) c,
sumIf(views, event_type = ${EVENT_TYPE.pageView}) as c,
min(min_time) min_time,
max(max_time) max_time
from website_event_stats_hourly "website_event"
${cohortQuery}
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and event_type = {eventType:UInt32}
${filterQuery}
group by session_id, visit_id
) as t;
) as t
left join (
select session_id, toUInt32(sumIf(views, event_type = ${EVENT_TYPE.customEvent})) as events_count
from website_event_stats_hourly
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
group by session_id
) as e using session_id;
`;
}

Expand Down
31 changes: 22 additions & 9 deletions src/queries/sql/reports/getInsights.ts
Original file line number Diff line number Diff line change
@@ -1,7 +1,7 @@
import { CLICKHOUSE, PRISMA, runQuery } from '@/lib/db';
import prisma from '@/lib/prisma';
import clickhouse from '@/lib/clickhouse';
import { EVENT_TYPE, FILTER_COLUMNS, SESSION_COLUMNS } from '@/lib/constants';
import { BOUNCE_THRESHOLD, EVENT_TYPE, FILTER_COLUMNS, SESSION_COLUMNS } from '@/lib/constants';
import { QueryFilters } from '@/lib/types';

export async function getInsights(
Expand Down Expand Up @@ -41,23 +41,30 @@ async function relationalQuery(
sum(t.c) as "views",
count(distinct t.session_id) as "visitors",
count(distinct t.visit_id) as "visits",
sum(case when t.c = 1 then 1 else 0 end) as "bounces",
sum(case when t.c = 1 and t.events_count < ${BOUNCE_THRESHOLD} then 1 else 0 end) as "bounces",
sum(${getTimestampDiffSQL('t.min_time', 't.max_time')}) as "totaltime",
${parseFieldsByName(fields)}
from (
select
${parseFields(fields)},
website_event.session_id,
website_event.visit_id,
count(*) as "c",
sum(case when website_event.event_type = ${EVENT_TYPE.pageView} then 1 else 0 end) as "c",
min(website_event.created_at) as "min_time",
max(website_event.created_at) as "max_time"
max(website_event.created_at) as "max_time",
max((
select count(*)
from website_event we2
where we2.website_id = website_event.website_id
and we2.session_id = website_event.session_id
and we2.created_at between {{startDate}} and {{endDate}}
and we2.event_type = ${EVENT_TYPE.customEvent}
)) as "events_count"
from website_event
${cohortQuery}
${joinSession}
where website_event.website_id = {{websiteId::uuid}}
and website_event.created_at between {{startDate}} and {{endDate}}
and event_type = {{eventType}}
${filterQuery}
group by ${parseFieldsByName(fields)},
website_event.session_id, website_event.visit_id
Expand All @@ -83,7 +90,6 @@ async function clickhouseQuery(
const { parseFilters, rawQuery } = clickhouse;
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, {
...filters,
eventType: EVENT_TYPE.pageView,
});

return rawQuery(
Expand All @@ -92,26 +98,33 @@ async function clickhouseQuery(
sum(t.c) as "views",
count(distinct t.session_id) as "visitors",
count(distinct t.visit_id) as "visits",
sum(if(t.c = 1, 1, 0)) as "bounces",
sumIf(1, t.c = 1 and ifNull(e.events_count, 0) < ${BOUNCE_THRESHOLD}) as "bounces",
sum(max_time-min_time) as "totaltime",
${parseFieldsByName(fields)}
from (
select
${parseFields(fields)},
session_id,
visit_id,
count(*) c,
countIf(event_type = ${EVENT_TYPE.pageView}) as c,
min(created_at) min_time,
max(created_at) max_time
from website_event
${cohortQuery}
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and event_type = {eventType:UInt32}
${filterQuery}
group by ${parseFieldsByName(fields)},
session_id, visit_id
) as t
left join (
select session_id, toUInt32(count()) as events_count
from website_event
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and event_type = ${EVENT_TYPE.customEvent}
group by session_id
) as e using session_id
group by ${parseFieldsByName(fields)}
order by 1 desc, 2 desc
limit 500
Expand Down
5 changes: 3 additions & 2 deletions src/queries/sql/reports/getUTM.ts
Original file line number Diff line number Diff line change
@@ -1,6 +1,7 @@
import clickhouse from '@/lib/clickhouse';
import { CLICKHOUSE, PRISMA, runQuery } from '@/lib/db';
import prisma from '@/lib/prisma';
import { EVENT_TYPE } from '@/lib/constants';

export async function getUTM(
...args: [
Expand Down Expand Up @@ -36,7 +37,7 @@ async function relationalQuery(
where website_id = {{websiteId::uuid}}
and created_at between {{startDate}} and {{endDate}}
and coalesce(url_query, '') != ''
and event_type = 1
and event_type = ${EVENT_TYPE.pageView}
group by 1
`,
{
Expand Down Expand Up @@ -65,7 +66,7 @@ async function clickhouseQuery(
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and url_query != ''
and event_type = 1
and event_type = ${EVENT_TYPE.pageView}
group by 1
`,
{
Expand Down
11 changes: 8 additions & 3 deletions src/queries/sql/sessions/getWebsiteSession.ts
Original file line number Diff line number Diff line change
@@ -1,6 +1,7 @@
import prisma from '@/lib/prisma';
import clickhouse from '@/lib/clickhouse';
import { runQuery, PRISMA, CLICKHOUSE } from '@/lib/db';
import { CLICKHOUSE, PRISMA, runQuery } from '@/lib/db';
import { EVENT_TYPE } from '@/lib/constants';

export async function getWebsiteSession(...args: [websiteId: string, sessionId: string]) {
return runQuery({
Expand Down Expand Up @@ -46,8 +47,12 @@ async function relationalQuery(websiteId: string, sessionId: string) {
session.city,
min(website_event.created_at) as min_time,
max(website_event.created_at) as max_time,
sum(case when website_event.event_type = 1 then 1 else 0 end) as views,
sum(case when website_event.event_type = 2 then 1 else 0 end) as events
sum(case when website_event.event_type = ${
EVENT_TYPE.pageView
} then 1 else 0 end) as views,
sum(case when website_event.event_type = ${
EVENT_TYPE.customEvent
} then 1 else 0 end) as events
from session
join website_event on website_event.session_id = session.session_id
where session.website_id = {{websiteId::uuid}}
Expand Down
6 changes: 3 additions & 3 deletions src/queries/sql/sessions/getWebsiteSessionStats.ts
Original file line number Diff line number Diff line change
@@ -1,5 +1,5 @@
import clickhouse from '@/lib/clickhouse';
import { EVENT_COLUMNS } from '@/lib/constants';
import { EVENT_COLUMNS, EVENT_TYPE } from '@/lib/constants';
import { CLICKHOUSE, PRISMA, runQuery } from '@/lib/db';
import prisma from '@/lib/prisma';
import { QueryFilters } from '@/lib/types';
Expand Down Expand Up @@ -33,7 +33,7 @@ async function relationalQuery(
count(distinct website_event.session_id) as "visitors",
count(distinct website_event.visit_id) as "visits",
count(distinct session.country) as "countries",
sum(case when website_event.event_type = 2 then 1 else 0 end) as "events"
sum(case when website_event.event_type = ${EVENT_TYPE.customEvent} then 1 else 0 end) as "events"
from website_event
${cohortQuery}
join session on website_event.session_id = session.session_id
Expand Down Expand Up @@ -61,7 +61,7 @@ async function clickhouseQuery(
if (EVENT_COLUMNS.some(item => Object.keys(filters).includes(item))) {
sql = `
select
sumIf(1, event_type = 1) as "pageviews",
sumIf(1, event_type = ${EVENT_TYPE.pageView}) as "pageviews",
uniq(session_id) as "visitors",
uniq(visit_id) as "visits",
uniq(country) as "countries",
Expand Down
8 changes: 4 additions & 4 deletions src/queries/sql/sessions/getWebsiteSessions.ts
Original file line number Diff line number Diff line change
@@ -1,5 +1,5 @@
import clickhouse from '@/lib/clickhouse';
import { EVENT_COLUMNS } from '@/lib/constants';
import { EVENT_COLUMNS, EVENT_TYPE } from '@/lib/constants';
import { CLICKHOUSE, getDatabaseType, POSTGRESQL, PRISMA, runQuery } from '@/lib/db';
import prisma from '@/lib/prisma';
import { PageParams, QueryFilters } from '@/lib/types';
Expand Down Expand Up @@ -39,7 +39,7 @@ async function relationalQuery(websiteId: string, filters: QueryFilters, pagePar
min(website_event.created_at) as "firstAt",
max(website_event.created_at) as "lastAt",
count(distinct website_event.visit_id) as "visits",
sum(case when website_event.event_type = 1 then 1 else 0 end) as "views",
sum(case when website_event.event_type = ${EVENT_TYPE.pageView} then 1 else 0 end) as "views",
max(website_event.created_at) as "createdAt"
from website_event
${cohortQuery}
Expand Down Expand Up @@ -96,7 +96,7 @@ async function clickhouseQuery(websiteId: string, filters: QueryFilters, pagePar
${getDateStringSQL('min(created_at)')} as firstAt,
${getDateStringSQL('max(created_at)')} as lastAt,
uniq(visit_id) as visits,
sumIf(views, event_type = 1) as views,
sumIf(views, event_type = ${EVENT_TYPE.pageView}) as views,
lastAt as createdAt
from website_event
${cohortQuery}
Expand Down Expand Up @@ -131,7 +131,7 @@ async function clickhouseQuery(websiteId: string, filters: QueryFilters, pagePar
${getDateStringSQL('min(min_time)')} as firstAt,
${getDateStringSQL('max(max_time)')} as lastAt,
uniq(visit_id) as visits,
sumIf(views, event_type = 1) as views,
sumIf(views, event_type = ${EVENT_TYPE.pageView}) as views,
lastAt as createdAt
from website_event_stats_hourly website_event
${cohortQuery}
Expand Down