add paging for relational raw query

This commit is contained in:
Francis Cao 2024-08-20 18:59:24 -07:00
parent 04e0b33622
commit 0220091cff
3 changed files with 107 additions and 37 deletions

View file

@ -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),
};
}),
};
});
);
}