mirror of
https://github.com/umami-software/umami.git
synced 2025-12-06 01:18:00 +01:00
121 lines
3.7 KiB
TypeScript
121 lines
3.7 KiB
TypeScript
import clickhouse from '@/lib/clickhouse';
|
|
import { CLICKHOUSE, getDatabaseType, POSTGRESQL, PRISMA, runQuery } from '@/lib/db';
|
|
import prisma from '@/lib/prisma';
|
|
import { PageParams, QueryFilters } from '@/lib/types';
|
|
|
|
export async function getWebsiteSessions(
|
|
...args: [websiteId: string, filters?: QueryFilters, pageParams?: PageParams]
|
|
) {
|
|
return runQuery({
|
|
[PRISMA]: () => relationalQuery(...args),
|
|
[CLICKHOUSE]: () => clickhouseQuery(...args),
|
|
});
|
|
}
|
|
|
|
async function relationalQuery(websiteId: string, filters: QueryFilters, pageParams: PageParams) {
|
|
const { pagedRawQuery, parseFilters } = prisma;
|
|
const { search } = pageParams;
|
|
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, {
|
|
...filters,
|
|
});
|
|
|
|
const db = getDatabaseType();
|
|
const like = db === POSTGRESQL ? 'ilike' : 'like';
|
|
|
|
return pagedRawQuery(
|
|
`
|
|
select
|
|
session.session_id as "id",
|
|
session.website_id as "websiteId",
|
|
website_event.hostname,
|
|
session.browser,
|
|
session.os,
|
|
session.device,
|
|
session.screen,
|
|
session.language,
|
|
session.country,
|
|
session.region,
|
|
session.city,
|
|
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",
|
|
max(website_event.created_at) as "createdAt"
|
|
from website_event
|
|
${cohortQuery}
|
|
join session on session.session_id = website_event.session_id
|
|
where website_event.website_id = {{websiteId::uuid}}
|
|
and website_event.created_at between {{startDate}} and {{endDate}}
|
|
${filterQuery}
|
|
${
|
|
search
|
|
? `and (distinct_id ${like} {{search}}
|
|
or city ${like} {{search}}
|
|
or browser ${like} {{search}}
|
|
or os ${like} {{search}}
|
|
or device ${like} {{search}})`
|
|
: ''
|
|
}
|
|
group by session.session_id,
|
|
session.website_id,
|
|
website_event.hostname,
|
|
session.browser,
|
|
session.os,
|
|
session.device,
|
|
session.screen,
|
|
session.language,
|
|
session.country,
|
|
session.region,
|
|
session.city
|
|
order by max(website_event.created_at) desc
|
|
`,
|
|
{ ...params, search: `%${search}%` },
|
|
pageParams,
|
|
);
|
|
}
|
|
|
|
async function clickhouseQuery(websiteId: string, filters: QueryFilters, pageParams?: PageParams) {
|
|
const { pagedQuery, parseFilters, getDateStringSQL } = clickhouse;
|
|
const { params, dateQuery, filterQuery, cohortQuery } = await parseFilters(websiteId, filters);
|
|
const { search } = pageParams;
|
|
|
|
return pagedQuery(
|
|
`
|
|
select
|
|
session_id as id,
|
|
website_id as websiteId,
|
|
hostname,
|
|
browser,
|
|
os,
|
|
device,
|
|
screen,
|
|
language,
|
|
country,
|
|
region,
|
|
city,
|
|
${getDateStringSQL('min(min_time)')} as firstAt,
|
|
${getDateStringSQL('max(max_time)')} as lastAt,
|
|
uniq(visit_id) as visits,
|
|
sumIf(views, event_type = 1) as views,
|
|
lastAt as createdAt
|
|
from website_event_stats_hourly website_event
|
|
${cohortQuery}
|
|
where website_id = {websiteId:UUID}
|
|
${dateQuery}
|
|
${filterQuery}
|
|
${
|
|
search
|
|
? `and ((positionCaseInsensitive(distinct_id, {search:String}) > 0)
|
|
or (positionCaseInsensitive(city, {search:String}) > 0)
|
|
or (positionCaseInsensitive(browser, {search:String}) > 0)
|
|
or (positionCaseInsensitive(os, {search:String}) > 0)
|
|
or (positionCaseInsensitive(device, {search:String}) > 0))`
|
|
: ''
|
|
}
|
|
group by session_id, website_id, hostname, browser, os, device, screen, language, country, region, city
|
|
order by lastAt desc
|
|
`,
|
|
{ ...params, search },
|
|
pageParams,
|
|
);
|
|
}
|