v1 revenue report for clickhouse

This commit is contained in:
Francis Cao 2024-09-26 15:36:48 -07:00
parent e173f375c7
commit 2707b39473
19 changed files with 427 additions and 243 deletions

View file

@ -10,9 +10,7 @@ export async function getRevenue(
endDate: Date;
unit: string;
timezone: string;
eventName: string;
revenueProperty: string;
userProperty: string;
currency: string;
},
]
) {
@ -29,23 +27,12 @@ async function relationalQuery(
endDate: Date;
unit: string;
timezone: string;
eventName: string;
revenueProperty: string;
userProperty: string;
},
): Promise<{
chart: { time: string; sum: number; avg: number; count: number; uniqueCount: number }[];
total: { sum: number; avg: number; count: number; uniqueCount: number };
}> {
const {
startDate,
endDate,
eventName,
revenueProperty,
userProperty,
timezone = 'UTC',
unit = 'day',
} = criteria;
const { startDate, endDate, timezone = 'UTC', unit = 'day' } = criteria;
const { getDateSQL, rawQuery } = prisma;
const chartRes = await rawQuery(
@ -63,7 +50,7 @@ async function relationalQuery(
and data_key in ({{revenueProperty}} , {{userProperty}})
group by 1
`,
{ websiteId, startDate, endDate, eventName, revenueProperty, userProperty },
{ websiteId, startDate, endDate },
);
const totalRes = await rawQuery(
@ -80,7 +67,7 @@ async function relationalQuery(
and data_key in ({{revenueProperty}} , {{userProperty}})
group by 1
`,
{ websiteId, startDate, endDate, eventName, revenueProperty, userProperty },
{ websiteId, startDate, endDate },
);
return { chart: chartRes, total: totalRes };
@ -91,59 +78,81 @@ async function clickhouseQuery(
criteria: {
startDate: Date;
endDate: Date;
eventName: string;
revenueProperty: string;
userProperty: string;
unit: string;
timezone: string;
currency: string;
},
): Promise<{
chart: { time: string; sum: number; avg: number; count: number; uniqueCount: number }[];
chart: { x: string; t: string; y: number }[];
country: { name: string; value: number }[];
total: { sum: number; avg: number; count: number; uniqueCount: number };
}> {
const {
startDate,
endDate,
eventName,
revenueProperty,
userProperty = '',
timezone = 'UTC',
unit = 'day',
} = criteria;
const { getDateStringSQL, getDateSQL, rawQuery } = clickhouse;
const chartRes = await rawQuery<{
time: string;
table: {
currency: string;
sum: number;
avg: number;
count: number;
uniqueCount: number;
}>(
}[];
}> {
const { startDate, endDate, timezone = 'UTC', unit = 'day', currency } = criteria;
const { getDateSQL, rawQuery } = clickhouse;
const chartRes = await rawQuery<
{
x: string;
t: string;
y: number;
}[]
>(
`
select
${getDateStringSQL('g.time', unit)} as time,
g.sum as sum,
g.avg as avg,
g.count as count,
g.uniqueCount as uniqueCount
from (
select
${getDateSQL('created_at', unit, timezone)} as time,
sumIf(number_value, data_key = {revenueProperty:String}) as sum,
avgIf(number_value, data_key = {revenueProperty:String}) as avg,
countIf(data_key = {revenueProperty:String}) as count,
uniqExactIf(string_value, data_key = {userProperty:String}) as uniqueCount
from event_data
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and event_name = {eventName:String}
and data_key in ({revenueProperty:String}, {userProperty:String})
group by time
) as g
order by time
event_name x,
${getDateSQL('created_at', unit, timezone)} t,
sum(coalesce(toDecimal64(number_value, 2), toDecimal64(string_value, 2))) y
from event_data
join (select event_id
from event_data
where positionCaseInsensitive(data_key, 'currency') > 0
and string_value = {currency:String}) currency
on currency.event_id = event_data.event_id
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and positionCaseInsensitive(data_key, 'revenue') > 0
group by x, t
order by t
`,
{ websiteId, startDate, endDate, eventName, revenueProperty, userProperty },
).then(result => result?.[0]);
{ websiteId, startDate, endDate, unit, timezone, currency },
);
const countryRes = await rawQuery<
{
name: string;
value: number;
}[]
>(
`
select
s.country as name,
sum(coalesce(toDecimal64(number_value, 2), toDecimal64(string_value, 2))) as value
from event_data ed
join (select event_id
from event_data
where positionCaseInsensitive(data_key, 'currency') > 0
and string_value = {currency:String}) c
on c.event_id = ed.event_id
join (select distinct website_id, session_id, country
from website_event_stats_hourly
where website_id = {websiteId:UUID}) s
on ed.website_id = s.website_id
and ed.session_id = s.session_id
where ed.website_id = {websiteId:UUID}
and ed.created_at between {startDate:DateTime64} and {endDate:DateTime64}
and positionCaseInsensitive(ed.data_key, 'revenue') > 0
group by s.country
`,
{ websiteId, startDate, endDate, currency },
);
const totalRes = await rawQuery<{
sum: number;
@ -152,19 +161,53 @@ async function clickhouseQuery(
uniqueCount: number;
}>(
`
select
sumIf(number_value, data_key = {revenueProperty:String}) as sum,
avgIf(number_value, data_key = {revenueProperty:String}) as avg,
countIf(data_key = {revenueProperty:String}) as count,
uniqExactIf(string_value, data_key = {userProperty:String}) as uniqueCount
from event_data
select
sum(coalesce(toDecimal64(number_value, 2), toDecimal64(string_value, 2))) as sum,
avg(coalesce(toDecimal64(number_value, 2), toDecimal64(string_value, 2))) as avg,
uniqExact(event_id) as count,
uniqExact(session_id) as uniqueCount
from event_data
join (select event_id
from event_data
where positionCaseInsensitive(data_key, 'currency') > 0
and string_value = {currency:String}) currency
on currency.event_id = event_data.event_id
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and event_name = {eventName:String}
and data_key in ({revenueProperty:String}, {userProperty:String})
and positionCaseInsensitive(data_key, 'revenue') > 0
`,
{ websiteId, startDate, endDate, eventName, revenueProperty, userProperty },
{ websiteId, startDate, endDate, currency },
).then(result => result?.[0]);
const tableRes = await rawQuery<
{
currency: string;
sum: number;
avg: number;
count: number;
uniqueCount: number;
}[]
>(
`
select
c.currency,
sum(coalesce(toDecimal64(ed.number_value, 2), toDecimal64(ed.string_value, 2))) as sum,
avg(coalesce(toDecimal64(ed.number_value, 2), toDecimal64(ed.string_value, 2))) as avg,
uniqExact(ed.event_id) as count,
uniqExact(ed.session_id) as uniqueCount
from event_data ed
join (select event_id, string_value as currency
from event_data
where positionCaseInsensitive(data_key, 'currency') > 0) c
ON c.event_id = ed.event_id
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and positionCaseInsensitive(data_key, 'revenue') > 0
group by c.currency
order by sum desc;
`,
{ websiteId, startDate, endDate, unit, timezone, currency },
);
return { chart: chartRes, total: totalRes };
return { chart: chartRes, country: countryRes, total: totalRes, table: tableRes };
}

View file

@ -34,8 +34,8 @@ async function relationalQuery(websiteId: string, filters: QueryFilters) {
async function clickhouseQuery(websiteId: string, filters: QueryFilters) {
const { timezone = 'utc' } = filters;
const { rawQuery } = clickhouse;
const { startDate, endDate } = filters;
const { rawQuery, parseFilters } = clickhouse;
const { params } = await parseFilters(websiteId, filters);
return rawQuery(
`
@ -48,7 +48,7 @@ async function clickhouseQuery(websiteId: string, filters: QueryFilters) {
group by time
order by time
`,
{ websiteId, startDate, endDate },
params,
).then(formatResults);
}