Merge remote-tracking branch 'origin/dev' into dev

This commit is contained in:
Mike Cao 2024-10-09 12:40:00 -07:00
commit 9d0da45c09
5 changed files with 143 additions and 70 deletions

View File

@ -11,7 +11,11 @@ export function RevenueParameters() {
const { id, parameters } = report || {}; const { id, parameters } = report || {};
const { websiteId, dateRange } = parameters || {}; const { websiteId, dateRange } = parameters || {};
const queryEnabled = websiteId && dateRange; const queryEnabled = websiteId && dateRange;
const { data: values = [] } = useRevenueValues(websiteId, dateRange.startDate, dateRange.endDate); const { data: values = [] } = useRevenueValues(
websiteId,
dateRange?.startDate,
dateRange?.endDate,
);
const handleSubmit = (data: any, e: any) => { const handleSubmit = (data: any, e: any) => {
e.stopPropagation(); e.stopPropagation();

View File

@ -29,7 +29,7 @@ export function RevenueTable() {
{row => row.count} {row => row.count}
</GridColumn> </GridColumn>
<GridColumn name="currency" label={formatMessage(labels.uniqueCustomers)} alignment="end"> <GridColumn name="currency" label={formatMessage(labels.uniqueCustomers)} alignment="end">
{row => row.uniqueCount} {row => row.unique_count}
</GridColumn> </GridColumn>
</GridTable> </GridTable>
); );

View File

@ -87,7 +87,7 @@ export function RevenueView({ isLoading }: RevenueViewProps) {
const metricData = useMemo(() => { const metricData = useMemo(() => {
if (!data) return []; if (!data) return [];
const { sum, avg, count, uniqueCount } = data.total; const { sum, avg, count, unique_count } = data.total;
return [ return [
{ {
@ -106,7 +106,7 @@ export function RevenueView({ isLoading }: RevenueViewProps) {
formatValue: formatLongNumber, formatValue: formatLongNumber,
}, },
{ {
value: uniqueCount, value: unique_count,
label: formatMessage(labels.uniqueCustomers), label: formatMessage(labels.uniqueCustomers),
formatValue: formatLongNumber, formatValue: formatLongNumber,
}, },
@ -121,6 +121,8 @@ export function RevenueView({ isLoading }: RevenueViewProps) {
return <MetricCard key={label} value={value} label={label} formatValue={formatValue} />; return <MetricCard key={label} value={value} label={label} formatValue={formatValue} />;
})} })}
</MetricsBar> </MetricsBar>
{data && (
<>
<BarChart <BarChart
minDate={dateRange?.startDate} minDate={dateRange?.startDate}
maxDate={dateRange?.endDate} maxDate={dateRange?.endDate}
@ -131,19 +133,19 @@ export function RevenueView({ isLoading }: RevenueViewProps) {
renderXLabel={renderDateLabels(dateRange?.unit, locale)} renderXLabel={renderDateLabels(dateRange?.unit, locale)}
isLoading={isLoading} isLoading={isLoading}
/> />
{data && (
<GridRow columns="two"> <GridRow columns="two">
<ListTable <ListTable
metric={formatMessage(labels.country)} metric={formatMessage(labels.country)}
data={data?.country.map(({ name, value }) => ({ data={data?.country.map(({ name, value }) => ({
x: name, x: name,
y: value, y: Number(value),
z: (value / data?.total.sum) * 100, z: (value / data?.total.sum) * 100,
}))} }))}
renderLabel={renderCountryName} renderLabel={renderCountryName}
/> />
<PieChart type="doughnut" data={countryData} /> <PieChart type="doughnut" data={countryData} />
</GridRow> </GridRow>
</>
)} )}
{showTable && <RevenueTable />} {showTable && <RevenueTable />}
</div> </div>

View File

@ -1,5 +1,5 @@
import clickhouse from 'lib/clickhouse'; 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 prisma from 'lib/prisma';
export async function getRevenue( export async function getRevenue(
@ -27,50 +27,118 @@ async function relationalQuery(
endDate: Date; endDate: Date;
unit: string; unit: string;
timezone: string; timezone: string;
currency: string;
}, },
): Promise<{ ): Promise<{
chart: { time: string; sum: number; avg: number; count: number; uniqueCount: number }[]; chart: { x: string; t: string; y: number }[];
total: { sum: number; avg: number; count: number; uniqueCount: number }; country: { name: string; value: number }[];
total: { sum: number; avg: number; count: number; unique_count: number };
table: {
currency: string;
sum: number;
avg: number;
count: number;
unique_count: number;
}[];
}> { }> {
const { startDate, endDate, timezone = 'UTC', unit = 'day' } = criteria; const { startDate, endDate, timezone = 'UTC', unit = 'day', currency } = criteria;
const { getDateSQL, rawQuery } = prisma; const { getDateSQL, rawQuery } = prisma;
const db = getDatabaseType();
const like = db === POSTGRESQL ? 'ilike' : 'like';
const chartRes = await rawQuery( const chartRes = await rawQuery(
` `
select select
${getDateSQL('website_event.created_at', unit, timezone)} time, we.event_name x,
sum(case when data_key = {{revenueProperty}} then number_value else 0 end) sum, ${getDateSQL('ed.created_at', unit, timezone)} t,
avg(case when data_key = {{revenueProperty}} then number_value else 0 end) avg, sum(coalesce(cast(number_value as decimal(10,2)), cast(string_value as decimal(10,2)))) y
count(case when data_key = {{revenueProperty}} then 1 else 0 end) count, from event_data ed
count(distinct {{userProperty}}) uniqueCount join website_event we
on we.event_id = ed.website_event_id
join (select website_event_id
from event_data from event_data
where website_event.website_id = {{websiteId::uuid}} where data_key ${like} '%currency%'
and website_event.created_at between {{startDate}} and {{endDate}} and string_value = {{currency}}) currency
and event_name = {{eventType}} on currency.website_event_id = ed.website_event_id
and data_key in ({{revenueProperty}} , {{userProperty}}) where ed.website_id = {{websiteId::uuid}}
group by 1 and ed.created_at between {{startDate}} and {{endDate}}
and ed.data_key ${like} '%revenue%'
group by x, t
order by t
`, `,
{ websiteId, startDate, endDate }, { websiteId, startDate, endDate, unit, timezone, currency },
);
const countryRes = await rawQuery(
`
select
s.country as name,
sum(coalesce(cast(number_value as decimal(10,2)), cast(string_value as decimal(10,2)))) value
from event_data ed
join website_event we
on we.event_id = ed.website_event_id
join session s
on s.session_id = we.session_id
join (select website_event_id
from event_data
where data_key ${like} '%currency%'
and string_value = 'USD') currency
on currency.website_event_id = ed.website_event_id
where ed.website_id = {{websiteId::uuid}}
and ed.created_at between {{startDate}} and {{endDate}}
and ed.data_key ${like} '%revenue%'
group by s.country
`,
{ websiteId, startDate, endDate, currency },
); );
const totalRes = await rawQuery( const totalRes = await rawQuery(
` `
select select
sum(case when data_key = {{revenueProperty}} then number_value else 0 end) sum, sum(coalesce(cast(number_value as decimal(10,2)), cast(string_value as decimal(10,2)))) as sum,
avg(case when data_key = {{revenueProperty}} then number_value else 0 end) avg, avg(coalesce(cast(number_value as decimal(10,2)), cast(string_value as decimal(10,2)))) as avg,
count(case when data_key = {{revenueProperty}} then 1 else 0 end) count, count(distinct event_id) as count,
count(distinct {{userProperty}}) uniqueCount count(distinct session_id) as unique_count
from event_data ed
join website_event we
on we.event_id = ed.website_event_id
join (select website_event_id
from event_data from event_data
where website_event.website_id = {{websiteId::uuid}} where data_key ${like} '%currency%'
and website_event.created_at between {{startDate}} and {{endDate}} and string_value = 'USD') currency
and event_name = {{eventType}} on currency.website_event_id = ed.website_event_id
and data_key in ({{revenueProperty}} , {{userProperty}}) where ed.website_id = {{websiteId::uuid}}
group by 1 and ed.created_at between {{startDate}} and {{endDate}}
and ed.data_key ${like} '%revenue%'
`, `,
{ websiteId, startDate, endDate }, { websiteId, startDate, endDate, currency },
).then(result => result?.[0]);
const tableRes = await rawQuery(
`
select
c.currency,
sum(coalesce(cast(number_value as decimal(10,2)), cast(string_value as decimal(10,2)))) as sum,
avg(coalesce(cast(number_value as decimal(10,2)), cast(string_value as decimal(10,2)))) as avg,
count(distinct ed.website_event_id) as count,
count(distinct we.session_id) as unique_count
from event_data ed
join website_event we
on we.event_id = ed.website_event_id
join (select website_event_id, string_value as currency
from event_data
where data_key ${like} '%currency%') c
on c.website_event_id = ed.website_event_id
where ed.website_id = {{websiteId::uuid}}
and ed.created_at between {{startDate}} and {{endDate}}
and ed.data_key ${like} '%revenue%'
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 };
} }
async function clickhouseQuery( async function clickhouseQuery(
@ -85,13 +153,13 @@ async function clickhouseQuery(
): Promise<{ ): Promise<{
chart: { x: string; t: string; y: number }[]; chart: { x: string; t: string; y: number }[];
country: { name: string; value: number }[]; country: { name: string; value: number }[];
total: { sum: number; avg: number; count: number; uniqueCount: number }; total: { sum: number; avg: number; count: number; unique_count: number };
table: { table: {
currency: string; currency: string;
sum: number; sum: number;
avg: number; avg: number;
count: number; count: number;
uniqueCount: number; unique_count: number;
}[]; }[];
}> { }> {
const { startDate, endDate, timezone = 'UTC', unit = 'day', currency } = criteria; const { startDate, endDate, timezone = 'UTC', unit = 'day', currency } = criteria;
@ -149,7 +217,6 @@ async function clickhouseQuery(
and ed.created_at between {startDate:DateTime64} and {endDate:DateTime64} and ed.created_at between {startDate:DateTime64} and {endDate:DateTime64}
and positionCaseInsensitive(ed.data_key, 'revenue') > 0 and positionCaseInsensitive(ed.data_key, 'revenue') > 0
group by s.country group by s.country
`, `,
{ websiteId, startDate, endDate, currency }, { websiteId, startDate, endDate, currency },
); );
@ -158,14 +225,14 @@ async function clickhouseQuery(
sum: number; sum: number;
avg: number; avg: number;
count: number; count: number;
uniqueCount: number; unique_count: number;
}>( }>(
` `
select select
sum(coalesce(toDecimal64(number_value, 2), toDecimal64(string_value, 2))) as sum, sum(coalesce(toDecimal64(number_value, 2), toDecimal64(string_value, 2))) as sum,
avg(coalesce(toDecimal64(number_value, 2), toDecimal64(string_value, 2))) as avg, avg(coalesce(toDecimal64(number_value, 2), toDecimal64(string_value, 2))) as avg,
uniqExact(event_id) as count, uniqExact(event_id) as count,
uniqExact(session_id) as uniqueCount uniqExact(session_id) as unique_count
from event_data from event_data
join (select event_id join (select event_id
from event_data from event_data
@ -185,7 +252,7 @@ async function clickhouseQuery(
sum: number; sum: number;
avg: number; avg: number;
count: number; count: number;
uniqueCount: number; unique_count: number;
}[] }[]
>( >(
` `
@ -194,12 +261,12 @@ async function clickhouseQuery(
sum(coalesce(toDecimal64(ed.number_value, 2), toDecimal64(ed.string_value, 2))) as sum, 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, avg(coalesce(toDecimal64(ed.number_value, 2), toDecimal64(ed.string_value, 2))) as avg,
uniqExact(ed.event_id) as count, uniqExact(ed.event_id) as count,
uniqExact(ed.session_id) as uniqueCount uniqExact(ed.session_id) as unique_count
from event_data ed from event_data ed
join (select event_id, string_value as currency join (select event_id, string_value as currency
from event_data from event_data
where positionCaseInsensitive(data_key, 'currency') > 0) c where positionCaseInsensitive(data_key, 'currency') > 0) c
ON c.event_id = ed.event_id on c.event_id = ed.event_id
where website_id = {websiteId:UUID} where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64} and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and positionCaseInsensitive(data_key, 'revenue') > 0 and positionCaseInsensitive(data_key, 'revenue') > 0

View File

@ -34,8 +34,8 @@ async function relationalQuery(
` `
select distinct string_value as currency select distinct string_value as currency
from event_data from event_data
where website_id = {websiteId:UUID} where website_id = {{websiteId::uuid}}
and created_at between {startDate:DateTime64} and {endDate:DateTime64} and created_at between {{startDate}} and {{endDate}}
and data_key ${like} '%currency%' and data_key ${like} '%currency%'
order by currency order by currency
`, `,