mirror of
https://github.com/umami-software/umami.git
synced 2026-02-04 04:37:11 +01:00
implement cohorts to clickhouse/pg library and all relevant queries
This commit is contained in:
parent
a753809a74
commit
e75d009df3
22 changed files with 220 additions and 10983 deletions
|
|
@ -89,6 +89,21 @@ function mapFilter(column: string, operator: string, name: string, type: string
|
|||
}
|
||||
}
|
||||
|
||||
function mapCohortFilter(column: string, operator: string, value: string) {
|
||||
switch (operator) {
|
||||
case OPERATORS.equals:
|
||||
return `${column} = '${value}'`;
|
||||
case OPERATORS.notEquals:
|
||||
return `${column} != '${value}'`;
|
||||
case OPERATORS.contains:
|
||||
return `positionCaseInsensitive(${column}, '${value}') > 0`;
|
||||
case OPERATORS.doesNotContain:
|
||||
return `positionCaseInsensitive(${column}, '${value}') = 0`;
|
||||
default:
|
||||
return '';
|
||||
}
|
||||
}
|
||||
|
||||
function getFilterQuery(filters: QueryFilters = {}, options: QueryOptions = {}) {
|
||||
const query = filtersToArray(filters, options).reduce((arr, { name, column, operator }) => {
|
||||
if (column) {
|
||||
|
|
@ -105,20 +120,40 @@ function getFilterQuery(filters: QueryFilters = {}, options: QueryOptions = {})
|
|||
return query.join('\n');
|
||||
}
|
||||
|
||||
function getCohortQuery(filters: QueryFilters = {}, options: QueryOptions = {}) {
|
||||
const query = filtersToArray(filters, options).reduce((arr, { name, column, operator }) => {
|
||||
if (column) {
|
||||
arr.push(`and ${mapFilter(column, operator, name)}`);
|
||||
function getCohortQuery(websiteId: string, filters: QueryFilters = {}, options: QueryOptions = {}) {
|
||||
const query = filtersToArray(filters, options).reduce(
|
||||
(arr, { name, column, operator, value }) => {
|
||||
if (column) {
|
||||
arr.push(
|
||||
`${arr.length === 0 ? 'where' : 'and'} ${mapCohortFilter(column, operator, value)}`,
|
||||
);
|
||||
|
||||
if (name === 'referrer') {
|
||||
arr.push(`and referrer_domain != hostname`);
|
||||
if (name === 'referrer') {
|
||||
arr.push(`and referrer_domain != hostname`);
|
||||
}
|
||||
}
|
||||
}
|
||||
|
||||
return arr;
|
||||
}, []);
|
||||
return arr;
|
||||
},
|
||||
[],
|
||||
);
|
||||
|
||||
return query.join('\n');
|
||||
if (query.length > 0) {
|
||||
// add website and date range filters
|
||||
query.push(`and website_id = '${websiteId}'`);
|
||||
query.push(
|
||||
`and created_at between parseDateTimeBestEffort('${filters.startDate}') and parseDateTimeBestEffort('${filters.endDate}')`,
|
||||
);
|
||||
|
||||
return `join
|
||||
(select distinct session_id
|
||||
from website_event
|
||||
${query.join('\n')}) cohort
|
||||
on cohort.session_id = website_event.session_id
|
||||
`;
|
||||
}
|
||||
|
||||
return '';
|
||||
}
|
||||
|
||||
function getDateQuery(filters: QueryFilters = {}) {
|
||||
|
|
@ -162,7 +197,7 @@ async function parseFilters(websiteId: string, filters: QueryFilters = {}, optio
|
|||
websiteId,
|
||||
startDate: maxDate(filters.startDate, new Date(website?.resetAt)),
|
||||
},
|
||||
cohortQuery: getCohortQuery(filters),
|
||||
cohortQuery: getCohortQuery(websiteId, filters?.cohort),
|
||||
};
|
||||
}
|
||||
|
||||
|
|
|
|||
|
|
@ -155,6 +155,24 @@ function mapFilter(column: string, operator: string, name: string, type: string
|
|||
}
|
||||
}
|
||||
|
||||
function mapCohortFilter(column: string, operator: string, value: string) {
|
||||
const db = getDatabaseType();
|
||||
const like = db === POSTGRESQL ? 'ilike' : 'like';
|
||||
|
||||
switch (operator) {
|
||||
case OPERATORS.equals:
|
||||
return `${column} = '${value}'`;
|
||||
case OPERATORS.notEquals:
|
||||
return `${column} != '${value}'`;
|
||||
case OPERATORS.contains:
|
||||
return `${column} ${like} '${value}'`;
|
||||
case OPERATORS.doesNotContain:
|
||||
return `${column} not ${like} '${value}'`;
|
||||
default:
|
||||
return '';
|
||||
}
|
||||
}
|
||||
|
||||
function getFilterQuery(filters: QueryFilters = {}, options: QueryOptions = {}): string {
|
||||
const query = filtersToArray(filters, options).reduce((arr, { name, column, operator }) => {
|
||||
if (column) {
|
||||
|
|
@ -173,6 +191,43 @@ function getFilterQuery(filters: QueryFilters = {}, options: QueryOptions = {}):
|
|||
return query.join('\n');
|
||||
}
|
||||
|
||||
function getCohortQuery(websiteId: string, filters: QueryFilters = {}, options: QueryOptions = {}) {
|
||||
const query = filtersToArray(filters, options).reduce(
|
||||
(arr, { name, column, operator, value }) => {
|
||||
if (column) {
|
||||
arr.push(
|
||||
`${arr.length === 0 ? 'where' : 'and'} ${mapCohortFilter(column, operator, value)}`,
|
||||
);
|
||||
|
||||
if (name === 'referrer') {
|
||||
arr.push(`and referrer_domain != hostname`);
|
||||
}
|
||||
}
|
||||
|
||||
return arr;
|
||||
},
|
||||
[],
|
||||
);
|
||||
|
||||
if (query.length > 0) {
|
||||
// add website and date range filters
|
||||
query.push(`and website_event.website_id = '${websiteId}'`);
|
||||
query.push(
|
||||
`and website_event.created_at between '${filters.startDate}'::timestamptz and '${filters.endDate}'::timestamptz`,
|
||||
);
|
||||
|
||||
return `join
|
||||
(select distinct website_event.session_id
|
||||
from website_event
|
||||
join session on session.session_id = website_event.session_id
|
||||
${query.join('\n')}) cohort
|
||||
on cohort.session_id = website_event.session_id
|
||||
`;
|
||||
}
|
||||
|
||||
return '';
|
||||
}
|
||||
|
||||
function getDateQuery(filters: QueryFilters = {}) {
|
||||
const { startDate, endDate } = filters;
|
||||
|
||||
|
|
@ -219,6 +274,7 @@ async function parseFilters(
|
|||
websiteId,
|
||||
startDate: maxDate(filters.startDate, website?.resetAt),
|
||||
},
|
||||
cohortQuery: getCohortQuery(websiteId, filters?.cohort),
|
||||
};
|
||||
}
|
||||
|
||||
|
|
|
|||
|
|
@ -158,6 +158,7 @@ export interface QueryFilters {
|
|||
event?: string;
|
||||
search?: string;
|
||||
tag?: string;
|
||||
cohort?: { [key: string]: string };
|
||||
}
|
||||
|
||||
export interface QueryOptions {
|
||||
|
|
|
|||
|
|
@ -14,7 +14,7 @@ export async function getEventDataFields(
|
|||
|
||||
async function relationalQuery(websiteId: string, filters: QueryFilters) {
|
||||
const { rawQuery, parseFilters, getDateSQL } = prisma;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, filters);
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, filters);
|
||||
|
||||
return rawQuery(
|
||||
`
|
||||
|
|
@ -29,6 +29,9 @@ async function relationalQuery(websiteId: string, filters: QueryFilters) {
|
|||
count(*) as "total"
|
||||
from event_data
|
||||
join website_event on website_event.event_id = event_data.website_event_id
|
||||
and website_event.website_id = {{websiteId::uuid}}
|
||||
and website_event.created_at between {{startDate}} and {{endDate}}
|
||||
${cohortQuery}
|
||||
where event_data.website_id = {{websiteId::uuid}}
|
||||
and event_data.created_at between {{startDate}} and {{endDate}}
|
||||
${filterQuery}
|
||||
|
|
@ -45,7 +48,7 @@ async function clickhouseQuery(
|
|||
filters: QueryFilters,
|
||||
): Promise<{ propertyName: string; dataType: number; propertyValue: string; total: number }[]> {
|
||||
const { rawQuery, parseFilters } = clickhouse;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, filters);
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, filters);
|
||||
|
||||
return rawQuery(
|
||||
`
|
||||
|
|
@ -56,7 +59,8 @@ async function clickhouseQuery(
|
|||
data_type = 4, toString(date_trunc('hour', date_value)),
|
||||
string_value) as "value",
|
||||
count(*) as "total"
|
||||
from event_data
|
||||
from event_data website_event
|
||||
${cohortQuery}
|
||||
where website_id = {websiteId:UUID}
|
||||
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
${filterQuery}
|
||||
|
|
|
|||
|
|
@ -17,7 +17,7 @@ async function relationalQuery(
|
|||
filters: QueryFilters & { propertyName?: string },
|
||||
) {
|
||||
const { rawQuery, parseFilters } = prisma;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, filters, {
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, filters, {
|
||||
columns: { propertyName: 'data_key' },
|
||||
});
|
||||
|
||||
|
|
@ -29,6 +29,9 @@ async function relationalQuery(
|
|||
count(*) as "total"
|
||||
from event_data
|
||||
join website_event on website_event.event_id = event_data.website_event_id
|
||||
and website_event.website_id = {{websiteId::uuid}}
|
||||
and website_event.created_at between {{startDate}} and {{endDate}}
|
||||
${cohortQuery}
|
||||
where event_data.website_id = {{websiteId::uuid}}
|
||||
and event_data.created_at between {{startDate}} and {{endDate}}
|
||||
${filterQuery}
|
||||
|
|
@ -45,7 +48,7 @@ async function clickhouseQuery(
|
|||
filters: QueryFilters & { propertyName?: string },
|
||||
): Promise<{ eventName: string; propertyName: string; total: number }[]> {
|
||||
const { rawQuery, parseFilters } = clickhouse;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, filters, {
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, filters, {
|
||||
columns: { propertyName: 'data_key' },
|
||||
});
|
||||
|
||||
|
|
@ -55,7 +58,8 @@ async function clickhouseQuery(
|
|||
event_name as eventName,
|
||||
data_key as propertyName,
|
||||
count(*) as total
|
||||
from event_data
|
||||
from event_data website_event
|
||||
${cohortQuery}
|
||||
where website_id = {websiteId:UUID}
|
||||
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
${filterQuery}
|
||||
|
|
|
|||
|
|
@ -18,7 +18,7 @@ export async function getEventDataStats(
|
|||
|
||||
async function relationalQuery(websiteId: string, filters: QueryFilters) {
|
||||
const { rawQuery, parseFilters } = prisma;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, filters);
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, filters);
|
||||
|
||||
return rawQuery(
|
||||
`
|
||||
|
|
@ -32,8 +32,12 @@ async function relationalQuery(websiteId: string, filters: QueryFilters) {
|
|||
data_key,
|
||||
count(*) as "total"
|
||||
from event_data
|
||||
where website_id = {{websiteId::uuid}}
|
||||
and created_at between {{startDate}} and {{endDate}}
|
||||
join website_event on website_event.event_id = event_data.website_event_id
|
||||
and website_event.website_id = {{websiteId::uuid}}
|
||||
and website_event.created_at between {{startDate}} and {{endDate}}
|
||||
${cohortQuery}
|
||||
where event_data.website_id = {{websiteId::uuid}}
|
||||
and event_data.created_at between {{startDate}} and {{endDate}}
|
||||
${filterQuery}
|
||||
group by website_event_id, data_key
|
||||
) as t
|
||||
|
|
@ -47,7 +51,7 @@ async function clickhouseQuery(
|
|||
filters: QueryFilters,
|
||||
): Promise<{ events: number; properties: number; records: number }[]> {
|
||||
const { rawQuery, parseFilters } = clickhouse;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, filters);
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, filters);
|
||||
|
||||
return rawQuery(
|
||||
`
|
||||
|
|
@ -60,7 +64,8 @@ async function clickhouseQuery(
|
|||
event_id,
|
||||
data_key,
|
||||
count(*) as "total"
|
||||
from event_data
|
||||
from event_data website_event
|
||||
${cohortQuery}
|
||||
where website_id = {websiteId:UUID}
|
||||
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
${filterQuery}
|
||||
|
|
|
|||
|
|
@ -20,7 +20,7 @@ async function relationalQuery(
|
|||
filters: QueryFilters & { eventName?: string; propertyName?: string },
|
||||
) {
|
||||
const { rawQuery, parseFilters, getDateSQL } = prisma;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, filters);
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, filters);
|
||||
|
||||
return rawQuery(
|
||||
`
|
||||
|
|
@ -33,6 +33,9 @@ async function relationalQuery(
|
|||
count(*) as "total"
|
||||
from event_data
|
||||
join website_event on website_event.event_id = event_data.website_event_id
|
||||
and website_event.website_id = {{websiteId::uuid}}
|
||||
and website_event.created_at between {{startDate}} and {{endDate}}
|
||||
${cohortQuery}
|
||||
where event_data.website_id = {{websiteId::uuid}}
|
||||
and event_data.created_at between {{startDate}} and {{endDate}}
|
||||
and event_data.data_key = {{propertyName}}
|
||||
|
|
@ -51,7 +54,7 @@ async function clickhouseQuery(
|
|||
filters: QueryFilters & { eventName?: string; propertyName?: string },
|
||||
): Promise<{ value: string; total: number }[]> {
|
||||
const { rawQuery, parseFilters } = clickhouse;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, filters);
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, filters);
|
||||
|
||||
return rawQuery(
|
||||
`
|
||||
|
|
@ -60,7 +63,8 @@ async function clickhouseQuery(
|
|||
data_type = 4, toString(date_trunc('hour', date_value)),
|
||||
string_value) as "value",
|
||||
count(*) as "total"
|
||||
from event_data
|
||||
from event_data website_event
|
||||
${cohortQuery}
|
||||
where website_id = {websiteId:UUID}
|
||||
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
and data_key = {propertyName:String}
|
||||
|
|
|
|||
|
|
@ -16,7 +16,7 @@ export async function getEventMetrics(
|
|||
async function relationalQuery(websiteId: string, filters: QueryFilters) {
|
||||
const { timezone = 'utc', unit = 'day' } = filters;
|
||||
const { rawQuery, getDateSQL, parseFilters } = prisma;
|
||||
const { filterQuery, joinSession, params } = await parseFilters(websiteId, {
|
||||
const { filterQuery, cohortQuery, joinSession, params } = await parseFilters(websiteId, {
|
||||
...filters,
|
||||
eventType: EVENT_TYPE.customEvent,
|
||||
});
|
||||
|
|
@ -28,6 +28,7 @@ async function relationalQuery(websiteId: string, filters: QueryFilters) {
|
|||
${getDateSQL('website_event.created_at', unit, timezone)} t,
|
||||
count(*) y
|
||||
from website_event
|
||||
${cohortQuery}
|
||||
${joinSession}
|
||||
where website_event.website_id = {{websiteId::uuid}}
|
||||
and website_event.created_at between {{startDate}} and {{endDate}}
|
||||
|
|
@ -46,20 +47,21 @@ async function clickhouseQuery(
|
|||
): Promise<{ x: string; t: string; y: number }[]> {
|
||||
const { timezone = 'UTC', unit = 'day' } = filters;
|
||||
const { rawQuery, getDateSQL, parseFilters } = clickhouse;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, {
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, {
|
||||
...filters,
|
||||
eventType: EVENT_TYPE.customEvent,
|
||||
});
|
||||
|
||||
let sql = '';
|
||||
|
||||
if (filterQuery) {
|
||||
if (filterQuery || cohortQuery) {
|
||||
sql = `
|
||||
select
|
||||
event_name x,
|
||||
${getDateSQL('created_at', unit, timezone)} t,
|
||||
count(*) y
|
||||
from website_event
|
||||
${cohortQuery}
|
||||
where website_id = {websiteId:UUID}
|
||||
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
and event_type = {eventType:UInt32}
|
||||
|
|
|
|||
|
|
@ -15,7 +15,7 @@ export function getWebsiteEvents(
|
|||
async function relationalQuery(websiteId: string, filters: QueryFilters, pageParams?: PageParams) {
|
||||
const { pagedRawQuery, parseFilters } = prisma;
|
||||
const { search } = pageParams;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, {
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, {
|
||||
...filters,
|
||||
});
|
||||
|
||||
|
|
@ -38,6 +38,7 @@ async function relationalQuery(websiteId: string, filters: QueryFilters, pagePar
|
|||
event_type as "eventType",
|
||||
event_name as "eventName"
|
||||
from website_event
|
||||
${cohortQuery}
|
||||
where website_id = {{websiteId::uuid}}
|
||||
and created_at between {{startDate}} and {{endDate}}
|
||||
${filterQuery}
|
||||
|
|
@ -56,7 +57,7 @@ async function relationalQuery(websiteId: string, filters: QueryFilters, pagePar
|
|||
|
||||
async function clickhouseQuery(websiteId: string, filters: QueryFilters, pageParams?: PageParams) {
|
||||
const { pagedQuery, parseFilters } = clickhouse;
|
||||
const { params, dateQuery, filterQuery } = await parseFilters(websiteId, filters);
|
||||
const { params, dateQuery, filterQuery, cohortQuery } = await parseFilters(websiteId, filters);
|
||||
const { search } = pageParams;
|
||||
|
||||
return pagedQuery(
|
||||
|
|
@ -75,6 +76,7 @@ async function clickhouseQuery(websiteId: string, filters: QueryFilters, pagePar
|
|||
event_type as eventType,
|
||||
event_name as eventName
|
||||
from website_event
|
||||
${cohortQuery}
|
||||
where website_id = {websiteId:UUID}
|
||||
${dateQuery}
|
||||
${filterQuery}
|
||||
|
|
|
|||
|
|
@ -12,7 +12,7 @@ export async function getChannelMetrics(...args: [websiteId: string, filters?: Q
|
|||
|
||||
async function relationalQuery(websiteId: string, filters: QueryFilters) {
|
||||
const { rawQuery, parseFilters } = prisma;
|
||||
const { params, filterQuery, dateQuery } = await parseFilters(websiteId, filters);
|
||||
const { params, filterQuery, cohortQuery, dateQuery } = await parseFilters(websiteId, filters);
|
||||
|
||||
return rawQuery(
|
||||
`
|
||||
|
|
@ -21,6 +21,7 @@ async function relationalQuery(websiteId: string, filters: QueryFilters) {
|
|||
url_query as query,
|
||||
count(distinct session_id) as visitors
|
||||
from website_event
|
||||
${cohortQuery}
|
||||
where website_id = {{websiteId::uuid}}
|
||||
${filterQuery}
|
||||
${dateQuery}
|
||||
|
|
@ -36,7 +37,7 @@ async function clickhouseQuery(
|
|||
filters: QueryFilters,
|
||||
): Promise<{ x: string; y: number }[]> {
|
||||
const { rawQuery, parseFilters } = clickhouse;
|
||||
const { params, filterQuery, dateQuery } = await parseFilters(websiteId, filters);
|
||||
const { params, filterQuery, cohortQuery, dateQuery } = await parseFilters(websiteId, filters);
|
||||
|
||||
const sql = `
|
||||
select
|
||||
|
|
@ -44,6 +45,7 @@ async function clickhouseQuery(
|
|||
url_query as query,
|
||||
uniq(session_id) as visitors
|
||||
from website_event
|
||||
${cohortQuery}
|
||||
where website_id = {websiteId:UUID}
|
||||
${filterQuery}
|
||||
${dateQuery}
|
||||
|
|
|
|||
|
|
@ -12,7 +12,7 @@ export async function getRealtimeActivity(...args: [websiteId: string, filters:
|
|||
|
||||
async function relationalQuery(websiteId: string, filters: QueryFilters) {
|
||||
const { rawQuery, parseFilters } = prisma;
|
||||
const { params, filterQuery, dateQuery } = await parseFilters(websiteId, filters);
|
||||
const { params, filterQuery, cohortQuery, dateQuery } = await parseFilters(websiteId, filters);
|
||||
|
||||
return rawQuery(
|
||||
`
|
||||
|
|
@ -27,6 +27,7 @@ async function relationalQuery(websiteId: string, filters: QueryFilters) {
|
|||
website_event.url_path as "urlPath",
|
||||
website_event.referrer_domain as "referrerDomain"
|
||||
from website_event
|
||||
${cohortQuery}
|
||||
inner join session
|
||||
on session.session_id = website_event.session_id
|
||||
where website_event.website_id = {{websiteId::uuid}}
|
||||
|
|
@ -41,7 +42,7 @@ async function relationalQuery(websiteId: string, filters: QueryFilters) {
|
|||
|
||||
async function clickhouseQuery(websiteId: string, filters: QueryFilters): Promise<{ x: number }> {
|
||||
const { rawQuery, parseFilters } = clickhouse;
|
||||
const { params, filterQuery, dateQuery } = await parseFilters(websiteId, filters);
|
||||
const { params, filterQuery, cohortQuery, dateQuery } = await parseFilters(websiteId, filters);
|
||||
|
||||
return rawQuery(
|
||||
`
|
||||
|
|
@ -56,6 +57,7 @@ async function clickhouseQuery(websiteId: string, filters: QueryFilters): Promis
|
|||
url_path as urlPath,
|
||||
referrer_domain as referrerDomain
|
||||
from website_event
|
||||
${cohortQuery}
|
||||
where website_id = {websiteId:UUID}
|
||||
${filterQuery}
|
||||
${dateQuery}
|
||||
|
|
|
|||
|
|
@ -23,7 +23,7 @@ async function relationalQuery(
|
|||
{ pageviews: number; visitors: number; visits: number; bounces: number; totaltime: number }[]
|
||||
> {
|
||||
const { getTimestampDiffSQL, parseFilters, rawQuery } = prisma;
|
||||
const { filterQuery, joinSession, params } = await parseFilters(websiteId, {
|
||||
const { filterQuery, cohortQuery, joinSession, params } = await parseFilters(websiteId, {
|
||||
...filters,
|
||||
eventType: EVENT_TYPE.pageView,
|
||||
});
|
||||
|
|
@ -44,6 +44,7 @@ async function relationalQuery(
|
|||
min(website_event.created_at) as "min_time",
|
||||
max(website_event.created_at) as "max_time"
|
||||
from website_event
|
||||
${cohortQuery}
|
||||
${joinSession}
|
||||
where website_event.website_id = {{websiteId::uuid}}
|
||||
and website_event.created_at between {{startDate}} and {{endDate}}
|
||||
|
|
@ -63,7 +64,7 @@ async function clickhouseQuery(
|
|||
{ pageviews: number; visitors: number; visits: number; bounces: number; totaltime: number }[]
|
||||
> {
|
||||
const { rawQuery, parseFilters } = clickhouse;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, {
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, {
|
||||
...filters,
|
||||
eventType: EVENT_TYPE.pageView,
|
||||
});
|
||||
|
|
@ -86,6 +87,7 @@ async function clickhouseQuery(
|
|||
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}
|
||||
|
|
@ -108,6 +110,7 @@ async function clickhouseQuery(
|
|||
min(min_time) min_time,
|
||||
max(max_time) max_time
|
||||
from umami.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}
|
||||
|
|
|
|||
|
|
@ -28,7 +28,7 @@ async function relationalQuery(
|
|||
) {
|
||||
const column = FILTER_COLUMNS[type] || type;
|
||||
const { rawQuery, parseFilters } = prisma;
|
||||
const { filterQuery, joinSession, params } = await parseFilters(
|
||||
const { filterQuery, cohortQuery, joinSession, params } = await parseFilters(
|
||||
websiteId,
|
||||
{
|
||||
...filters,
|
||||
|
|
@ -68,6 +68,7 @@ async function relationalQuery(
|
|||
select ${column} x,
|
||||
${column === 'referrer_domain' ? 'count(distinct website_event.session_id)' : 'count(*)'} as y
|
||||
from website_event
|
||||
${cohortQuery}
|
||||
${joinSession}
|
||||
${entryExitQuery}
|
||||
where website_event.website_id = {{websiteId::uuid}}
|
||||
|
|
@ -93,7 +94,7 @@ async function clickhouseQuery(
|
|||
): Promise<{ x: string; y: number }[]> {
|
||||
const column = FILTER_COLUMNS[type] || type;
|
||||
const { rawQuery, parseFilters } = clickhouse;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, {
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, {
|
||||
...filters,
|
||||
eventType: column === 'event_name' ? EVENT_TYPE.customEvent : EVENT_TYPE.pageView,
|
||||
});
|
||||
|
|
@ -127,6 +128,7 @@ async function clickhouseQuery(
|
|||
select ${column} x,
|
||||
${column === 'referrer_domain' ? 'uniq(session_id)' : 'count(*)'} as y
|
||||
from website_event
|
||||
${cohortQuery}
|
||||
${entryExitQuery}
|
||||
where website_id = {websiteId:UUID}
|
||||
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
|
|
@ -165,6 +167,7 @@ async function clickhouseQuery(
|
|||
from (
|
||||
select ${columnQuery} as t
|
||||
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}
|
||||
|
|
|
|||
|
|
@ -14,7 +14,7 @@ export async function getPageviewStats(...args: [websiteId: string, filters: Que
|
|||
async function relationalQuery(websiteId: string, filters: QueryFilters) {
|
||||
const { timezone = 'utc', unit = 'day' } = filters;
|
||||
const { getDateSQL, parseFilters, rawQuery } = prisma;
|
||||
const { filterQuery, joinSession, params } = await parseFilters(websiteId, {
|
||||
const { filterQuery, cohortQuery, joinSession, params } = await parseFilters(websiteId, {
|
||||
...filters,
|
||||
eventType: EVENT_TYPE.pageView,
|
||||
});
|
||||
|
|
@ -25,6 +25,7 @@ async function relationalQuery(websiteId: string, filters: QueryFilters) {
|
|||
${getDateSQL('website_event.created_at', unit, timezone)} x,
|
||||
count(*) y
|
||||
from website_event
|
||||
${cohortQuery}
|
||||
${joinSession}
|
||||
where website_event.website_id = {{websiteId::uuid}}
|
||||
and website_event.created_at between {{startDate}} and {{endDate}}
|
||||
|
|
@ -43,7 +44,7 @@ async function clickhouseQuery(
|
|||
): Promise<{ x: string; y: number }[]> {
|
||||
const { timezone = 'utc', unit = 'day' } = filters;
|
||||
const { parseFilters, rawQuery, getDateSQL } = clickhouse;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, {
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, {
|
||||
...filters,
|
||||
eventType: EVENT_TYPE.pageView,
|
||||
});
|
||||
|
|
@ -60,6 +61,7 @@ async function clickhouseQuery(
|
|||
${getDateSQL('website_event.created_at', unit, timezone)} as t,
|
||||
count(*) as y
|
||||
from website_event
|
||||
${cohortQuery}
|
||||
where website_id = {websiteId:UUID}
|
||||
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
and event_type = {eventType:UInt32}
|
||||
|
|
@ -78,6 +80,7 @@ async function clickhouseQuery(
|
|||
${getDateSQL('website_event.created_at', unit, timezone)} as t,
|
||||
sum(views)as y
|
||||
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}
|
||||
|
|
|
|||
|
|
@ -24,7 +24,7 @@ async function relationalQuery(
|
|||
}[]
|
||||
> {
|
||||
const { getTimestampDiffSQL, parseFilters, rawQuery } = prisma;
|
||||
const { filterQuery, joinSession, params } = await parseFilters(
|
||||
const { filterQuery, cohortQuery, joinSession, params } = await parseFilters(
|
||||
websiteId,
|
||||
{
|
||||
...filters,
|
||||
|
|
@ -53,6 +53,7 @@ async function relationalQuery(
|
|||
min(website_event.created_at) as "min_time",
|
||||
max(website_event.created_at) as "max_time"
|
||||
from website_event
|
||||
${cohortQuery}
|
||||
${joinSession}
|
||||
where website_event.website_id = {{websiteId::uuid}}
|
||||
and website_event.created_at between {{startDate}} and {{endDate}}
|
||||
|
|
@ -80,7 +81,7 @@ async function clickhouseQuery(
|
|||
}[]
|
||||
> {
|
||||
const { parseFilters, rawQuery } = clickhouse;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, {
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, {
|
||||
...filters,
|
||||
eventType: EVENT_TYPE.pageView,
|
||||
});
|
||||
|
|
@ -103,6 +104,7 @@ async function clickhouseQuery(
|
|||
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}
|
||||
|
|
|
|||
|
|
@ -17,7 +17,7 @@ async function relationalQuery(
|
|||
filters: QueryFilters & { propertyName?: string },
|
||||
) {
|
||||
const { rawQuery, parseFilters } = prisma;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, filters, {
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, filters, {
|
||||
columns: { propertyName: 'data_key' },
|
||||
});
|
||||
|
||||
|
|
@ -25,12 +25,13 @@ async function relationalQuery(
|
|||
`
|
||||
select
|
||||
data_key as "propertyName",
|
||||
count(distinct d.session_id) as "total"
|
||||
from website_event e
|
||||
join session_data d
|
||||
on d.session_id = e.session_id
|
||||
where e.website_id = {{websiteId::uuid}}
|
||||
and e.created_at between {{startDate}} and {{endDate}}
|
||||
count(distinct session_data.session_id) as "total"
|
||||
from website_event
|
||||
${cohortQuery}
|
||||
join session_data
|
||||
on session_data.session_id = website_event.session_id
|
||||
where website_event.website_id = {{websiteId::uuid}}
|
||||
and website_event.created_at between {{startDate}} and {{endDate}}
|
||||
${filterQuery}
|
||||
group by 1
|
||||
order by 2 desc
|
||||
|
|
@ -45,7 +46,7 @@ async function clickhouseQuery(
|
|||
filters: QueryFilters & { propertyName?: string },
|
||||
): Promise<{ propertyName: string; total: number }[]> {
|
||||
const { rawQuery, parseFilters } = clickhouse;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, filters, {
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, filters, {
|
||||
columns: { propertyName: 'data_key' },
|
||||
});
|
||||
|
||||
|
|
@ -53,13 +54,14 @@ async function clickhouseQuery(
|
|||
`
|
||||
select
|
||||
data_key as propertyName,
|
||||
count(distinct d.session_id) as total
|
||||
from website_event e
|
||||
join session_data d final
|
||||
on d.session_id = e.session_id
|
||||
where e.website_id = {websiteId:UUID}
|
||||
and e.created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
and d.data_key != ''
|
||||
count(distinct session_data.session_id) as total
|
||||
from website_event
|
||||
${cohortQuery}
|
||||
join session_data final
|
||||
on session_data.session_id = website_event.session_id
|
||||
where website_event.website_id = {websiteId:UUID}
|
||||
and website_event.created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
and session_data.data_key != ''
|
||||
${filterQuery}
|
||||
group by 1
|
||||
order by 2 desc
|
||||
|
|
|
|||
|
|
@ -17,7 +17,7 @@ async function relationalQuery(
|
|||
filters: QueryFilters & { propertyName?: string },
|
||||
) {
|
||||
const { rawQuery, parseFilters, getDateSQL } = prisma;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, filters);
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, filters);
|
||||
|
||||
return rawQuery(
|
||||
`
|
||||
|
|
@ -27,13 +27,14 @@ async function relationalQuery(
|
|||
when data_type = 4 then ${getDateSQL('date_value', 'hour')}
|
||||
else string_value
|
||||
end as "value",
|
||||
count(distinct d.session_id) as "total"
|
||||
count(distinct session_data.session_id) as "total"
|
||||
from website_event e
|
||||
${cohortQuery}
|
||||
join session_data d
|
||||
on d.session_id = e.session_id
|
||||
where e.website_id = {{websiteId::uuid}}
|
||||
and e.created_at between {{startDate}} and {{endDate}}
|
||||
and d.data_key = {{propertyName}}
|
||||
on session_data.session_id = website_event.session_id
|
||||
where website_event.website_id = {{websiteId::uuid}}
|
||||
and website_event.created_at between {{startDate}} and {{endDate}}
|
||||
and session_data.data_key = {{propertyName}}
|
||||
${filterQuery}
|
||||
group by value
|
||||
order by 2 desc
|
||||
|
|
@ -48,7 +49,7 @@ async function clickhouseQuery(
|
|||
filters: QueryFilters & { propertyName?: string },
|
||||
): Promise<{ propertyName: string; dataType: number; propertyValue: string; total: number }[]> {
|
||||
const { rawQuery, parseFilters } = clickhouse;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, filters);
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, filters);
|
||||
|
||||
return rawQuery(
|
||||
`
|
||||
|
|
@ -56,13 +57,14 @@ async function clickhouseQuery(
|
|||
multiIf(data_type = 2, replaceAll(string_value, '.0000', ''),
|
||||
data_type = 4, toString(date_trunc('hour', date_value)),
|
||||
string_value) as "value",
|
||||
uniq(d.session_id) as "total"
|
||||
uniq(session_data.session_id) as "total"
|
||||
from website_event e
|
||||
${cohortQuery}
|
||||
join session_data d final
|
||||
on d.session_id = e.session_id
|
||||
where e.website_id = {websiteId:UUID}
|
||||
and e.created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
and d.data_key = {propertyName:String}
|
||||
on session_data.session_id = website_event.session_id
|
||||
where website_event.website_id = {websiteId:UUID}
|
||||
and website_event.created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
and session_data.data_key = {propertyName:String}
|
||||
${filterQuery}
|
||||
group by value
|
||||
order by 2 desc
|
||||
|
|
|
|||
|
|
@ -28,7 +28,7 @@ async function relationalQuery(
|
|||
) {
|
||||
const column = FILTER_COLUMNS[type] || type;
|
||||
const { parseFilters, rawQuery } = prisma;
|
||||
const { filterQuery, joinSession, params } = await parseFilters(
|
||||
const { filterQuery, cohortQuery, joinSession, params } = await parseFilters(
|
||||
websiteId,
|
||||
{
|
||||
...filters,
|
||||
|
|
@ -47,6 +47,7 @@ async function relationalQuery(
|
|||
count(distinct website_event.session_id) y
|
||||
${includeCountry ? ', country' : ''}
|
||||
from website_event
|
||||
${cohortQuery}
|
||||
${joinSession}
|
||||
where website_event.website_id = {{websiteId::uuid}}
|
||||
and website_event.created_at between {{startDate}} and {{endDate}}
|
||||
|
|
@ -71,7 +72,7 @@ async function clickhouseQuery(
|
|||
): Promise<{ x: string; y: number }[]> {
|
||||
const column = FILTER_COLUMNS[type] || type;
|
||||
const { parseFilters, rawQuery } = clickhouse;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, {
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, {
|
||||
...filters,
|
||||
eventType: EVENT_TYPE.pageView,
|
||||
});
|
||||
|
|
@ -86,6 +87,7 @@ async function clickhouseQuery(
|
|||
count(distinct session_id) y
|
||||
${includeCountry ? ', country' : ''}
|
||||
from website_event
|
||||
${cohortQuery}
|
||||
where website_id = {websiteId:UUID}
|
||||
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
and event_type = {eventType:UInt32}
|
||||
|
|
@ -103,6 +105,7 @@ async function clickhouseQuery(
|
|||
uniq(session_id) y
|
||||
${includeCountry ? ', country' : ''}
|
||||
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}
|
||||
|
|
|
|||
|
|
@ -14,7 +14,7 @@ export async function getSessionStats(...args: [websiteId: string, filters: Quer
|
|||
async function relationalQuery(websiteId: string, filters: QueryFilters) {
|
||||
const { timezone = 'utc', unit = 'day' } = filters;
|
||||
const { getDateSQL, parseFilters, rawQuery } = prisma;
|
||||
const { filterQuery, joinSession, params } = await parseFilters(websiteId, {
|
||||
const { filterQuery, cohortQuery, joinSession, params } = await parseFilters(websiteId, {
|
||||
...filters,
|
||||
eventType: EVENT_TYPE.pageView,
|
||||
});
|
||||
|
|
@ -25,6 +25,7 @@ async function relationalQuery(websiteId: string, filters: QueryFilters) {
|
|||
${getDateSQL('website_event.created_at', unit, timezone)} x,
|
||||
count(distinct website_event.session_id) y
|
||||
from website_event
|
||||
${cohortQuery}
|
||||
${joinSession}
|
||||
where website_event.website_id = {{websiteId::uuid}}
|
||||
and website_event.created_at between {{startDate}} and {{endDate}}
|
||||
|
|
@ -43,7 +44,7 @@ async function clickhouseQuery(
|
|||
): Promise<{ x: string; y: number }[]> {
|
||||
const { timezone = 'utc', unit = 'day' } = filters;
|
||||
const { parseFilters, rawQuery, getDateSQL } = clickhouse;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, {
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, {
|
||||
...filters,
|
||||
eventType: EVENT_TYPE.pageView,
|
||||
});
|
||||
|
|
@ -60,6 +61,7 @@ async function clickhouseQuery(
|
|||
${getDateSQL('website_event.created_at', unit, timezone)} as t,
|
||||
count(distinct session_id) as y
|
||||
from website_event
|
||||
${cohortQuery}
|
||||
where website_id = {websiteId:UUID}
|
||||
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
and event_type = {eventType:UInt32}
|
||||
|
|
@ -78,6 +80,7 @@ async function clickhouseQuery(
|
|||
${getDateSQL('website_event.created_at', unit, timezone)} as t,
|
||||
uniq(session_id) as y
|
||||
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}
|
||||
|
|
|
|||
|
|
@ -21,7 +21,7 @@ async function relationalQuery(
|
|||
{ pageviews: number; visitors: number; visits: number; countries: number; events: number }[]
|
||||
> {
|
||||
const { parseFilters, rawQuery } = prisma;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, {
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, {
|
||||
...filters,
|
||||
});
|
||||
|
||||
|
|
@ -34,6 +34,7 @@ async function relationalQuery(
|
|||
count(distinct session.country) as "countries",
|
||||
sum(case when website_event.event_type = 2 then 1 else 0 end) as "events"
|
||||
from website_event
|
||||
${cohortQuery}
|
||||
join session on website_event.session_id = session.session_id
|
||||
where website_event.website_id = {{websiteId::uuid}}
|
||||
and website_event.created_at between {{startDate}} and {{endDate}}
|
||||
|
|
@ -50,7 +51,7 @@ async function clickhouseQuery(
|
|||
{ pageviews: number; visitors: number; visits: number; countries: number; events: number }[]
|
||||
> {
|
||||
const { rawQuery, parseFilters } = clickhouse;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, {
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, {
|
||||
...filters,
|
||||
});
|
||||
|
||||
|
|
@ -63,6 +64,7 @@ async function clickhouseQuery(
|
|||
uniq(country) as "countries",
|
||||
sum(length(event_name)) as "events"
|
||||
from umami.website_event_stats_hourly "website_event"
|
||||
${cohortQuery}
|
||||
where website_id = {websiteId:UUID}
|
||||
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
${filterQuery}
|
||||
|
|
|
|||
|
|
@ -15,7 +15,7 @@ export async function getWebsiteSessions(
|
|||
async function relationalQuery(websiteId: string, filters: QueryFilters, pageParams: PageParams) {
|
||||
const { pagedRawQuery, parseFilters } = prisma;
|
||||
const { search } = pageParams;
|
||||
const { filterQuery, params } = await parseFilters(websiteId, {
|
||||
const { filterQuery, cohortQuery, params } = await parseFilters(websiteId, {
|
||||
...filters,
|
||||
});
|
||||
|
||||
|
|
@ -42,6 +42,7 @@ async function relationalQuery(websiteId: string, filters: QueryFilters, pagePar
|
|||
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}}
|
||||
|
|
@ -75,7 +76,7 @@ async function relationalQuery(websiteId: string, filters: QueryFilters, pagePar
|
|||
|
||||
async function clickhouseQuery(websiteId: string, filters: QueryFilters, pageParams?: PageParams) {
|
||||
const { pagedQuery, parseFilters, getDateStringSQL } = clickhouse;
|
||||
const { params, dateQuery, filterQuery } = await parseFilters(websiteId, filters);
|
||||
const { params, dateQuery, filterQuery, cohortQuery } = await parseFilters(websiteId, filters);
|
||||
const { search } = pageParams;
|
||||
|
||||
return pagedQuery(
|
||||
|
|
@ -97,7 +98,8 @@ async function clickhouseQuery(websiteId: string, filters: QueryFilters, pagePar
|
|||
uniq(visit_id) as visits,
|
||||
sumIf(views, event_type = 1) as views,
|
||||
lastAt as createdAt
|
||||
from website_event_stats_hourly
|
||||
from website_event_stats_hourly website_event
|
||||
${cohortQuery}
|
||||
where website_id = {websiteId:UUID}
|
||||
${dateQuery}
|
||||
${filterQuery}
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue