diff --git a/src/lib/prisma.ts b/src/lib/prisma.ts index 8c4f8c5c..c450f1f0 100644 --- a/src/lib/prisma.ts +++ b/src/lib/prisma.ts @@ -261,6 +261,32 @@ async function pagedQuery(model: string, criteria: T, pageParams: PageParams) return { data, count, page: +page, pageSize: size, orderBy }; } +async function pagedRawQuery( + query: string, + queryParams: { [key: string]: any }, + pageParams: PageParams = {}, +) { + const { page = 1, pageSize, orderBy, sortDescending = false } = pageParams; + const size = +pageSize || DEFAULT_PAGE_SIZE; + const offset = +size * (page - 1); + const direction = sortDescending ? 'desc' : 'asc'; + + const statements = [ + orderBy && `order by ${orderBy} ${direction}`, + +size > 0 && `limit ${+size} offset ${offset}`, + ] + .filter(n => n) + .join('\n'); + + const count = await rawQuery(`select count(*) as num from (${query}) t`, queryParams).then( + res => res[0].num, + ); + + const data = await rawQuery(`${query}${statements}`, queryParams); + + return { data, count, page: +page, pageSize: size, orderBy }; +} + function getQueryMode(): { mode?: Prisma.QueryMode } { const db = getDatabaseType(); @@ -311,6 +337,7 @@ export default { getSearchSQL, getQueryMode, pagedQuery, + pagedRawQuery, parseFilters, rawQuery, }; diff --git a/src/queries/analytics/events/getWebsiteEvents.ts b/src/queries/analytics/events/getWebsiteEvents.ts index 60a932f5..5ac42dbb 100644 --- a/src/queries/analytics/events/getWebsiteEvents.ts +++ b/src/queries/analytics/events/getWebsiteEvents.ts @@ -1,5 +1,5 @@ import clickhouse from 'lib/clickhouse'; -import { CLICKHOUSE, PRISMA, runQuery } from 'lib/db'; +import { CLICKHOUSE, getDatabaseType, POSTGRESQL, PRISMA, runQuery } from 'lib/db'; import prisma from 'lib/prisma'; import { PageParams, QueryFilters } from 'lib/types'; @@ -13,23 +13,47 @@ export function getWebsiteEvents( } async function relationalQuery(websiteId: string, filters: QueryFilters, pageParams?: PageParams) { - const { pagedQuery } = prisma; + const { pagedRawQuery, parseFilters } = prisma; const { query } = pageParams; - const { startDate, endDate } = filters; + const { filterQuery, params } = await parseFilters(websiteId, { + ...filters, + }); - const where = { - websiteId, - createdAt: { - lte: endDate, - gte: startDate, - }, - ...prisma.getSearchParameters(query, [{ eventName: 'contains' }, { urlPath: 'contains' }]), - }; + const db = getDatabaseType(); + const like = db === POSTGRESQL ? 'ilike' : 'like'; - return pagedQuery( - 'websiteEvent', - { where }, - { orderBy: 'createdAt', sortDescending: true, ...pageParams }, + return pagedRawQuery( + ` + with events as ( + select + event_id as "id", + website_id as "websiteId", + session_id as "sessionId", + created_at as "createdAt", + url_path as "urlPath", + url_query as "urlQuery", + referrer_path as "referrerPath", + referrer_query as "referrerQuery", + referrer_domain as "referrerDomain", + page_title as "pageTitle", + event_type as "eventType", + event_name as "eventName" + from website_event + where website_id = {{websiteId::uuid}} + and created_at between {{startDate}} and {{endDate}} + ${filterQuery} + ${ + query + ? `and (event_name ${like} {{query}} + or url_path ${like} {{query}})` + : '' + } + order by created_at desc + limit 1000) + select * from events + `, + { ...params, query: `%${query}%` }, + pageParams, ); } diff --git a/src/queries/analytics/sessions/getWebsiteSessions.ts b/src/queries/analytics/sessions/getWebsiteSessions.ts index 1ea3ef49..81e007ca 100644 --- a/src/queries/analytics/sessions/getWebsiteSessions.ts +++ b/src/queries/analytics/sessions/getWebsiteSessions.ts @@ -1,6 +1,6 @@ -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 prisma from 'lib/prisma'; import { PageParams, QueryFilters } from 'lib/types'; export async function getWebsiteSessions( @@ -13,14 +13,44 @@ export async function getWebsiteSessions( } async function relationalQuery(websiteId: string, filters: QueryFilters, pageParams: PageParams) { - const { pagedQuery } = prisma; - - const where = { + const { pagedRawQuery, parseFilters } = prisma; + const { filterQuery, params } = await parseFilters(websiteId, { ...filters, - id: websiteId, - }; + }); - return pagedQuery('session', { where }, pageParams); + return pagedRawQuery( + ` + with sessions as ( + select + s.session_id as "id", + s.website_id as "websiteId", + hostname, + browser, + os, + device, + screen, + language, + country, + subdivision1, + city, + min(we.created_at) as "firstAt", + max(we.created_at) as "lastAt", + count(distinct we.visit_id) as "visits", + sum(case when we.event_type = 1 then 1 else 0 end) as "views", + max(we.created_at) as "createdAt" + from website_event we + join session s on s.session_id = we.session_id + where we.website_id = {{websiteId::uuid}} + and we.created_at between {{startDate}} and {{endDate}} + ${filterQuery} + group by s.session_id, s.website_id, s.hostname, s.browser, s.os, s.device, s.screen, s.language, s.country, s.subdivision1, s.city + order by max(we.created_at) desc + limit 1000) + select * from sessions + `, + params, + pageParams, + ); } async function clickhouseQuery(websiteId: string, filters: QueryFilters, pageParams?: PageParams) { @@ -45,7 +75,8 @@ 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 = 1) as views, + lastAt as createdAt from website_event_stats_hourly where website_id = {websiteId:UUID} ${dateQuery} @@ -57,17 +88,5 @@ async function clickhouseQuery(websiteId: string, filters: QueryFilters, pagePar `, params, pageParams, - ).then((result: any) => { - return { - ...result, - data: result.data.map((row: any) => { - return { - ...row, - createdAt: row.lastAt, - visits: Number(row.visits), - views: Number(row.views), - }; - }), - }; - }); + ); }