ch attribution report, schema changes, and migration

This commit is contained in:
Francis Cao 2025-04-13 18:12:03 -07:00
parent 64dcc5af80
commit b9a2145766
10 changed files with 689 additions and 353 deletions

View file

@ -28,8 +28,13 @@ CREATE TABLE umami.website_event_new
referrer_query String,
referrer_domain String,
page_title String,
--clickIDs
gclid String,
fbclid String,
msclkid String,
ttclid String,
li_fat_id String,
twclid String,
--events
event_type UInt32,
event_name String,
@ -71,6 +76,10 @@ CREATE TABLE umami.website_event_stats_hourly_new
page_title SimpleAggregateFunction(groupArrayArray, Array(String)),
gclid SimpleAggregateFunction(groupArrayArray, Array(String)),
fbclid SimpleAggregateFunction(groupArrayArray, Array(String)),
msclkid SimpleAggregateFunction(groupArrayArray, Array(String)),
ttclid SimpleAggregateFunction(groupArrayArray, Array(String)),
li_fat_id SimpleAggregateFunction(groupArrayArray, Array(String)),
twclid SimpleAggregateFunction(groupArrayArray, Array(String)),
event_type UInt32,
event_name SimpleAggregateFunction(groupArrayArray, Array(String)),
views SimpleAggregateFunction(sum, UInt64),
@ -119,6 +128,10 @@ SELECT
page_title,
gclid,
fbclid,
msclkid,
ttclid,
li_fat_id,
twclid,
event_type,
event_name,
views,
@ -152,6 +165,10 @@ FROM (SELECT
arrayFilter(x -> x != '', groupArray(page_title)) page_title,
arrayFilter(x -> x != '', groupArray(gclid)) gclid,
arrayFilter(x -> x != '', groupArray(fbclid)) fbclid,
arrayFilter(x -> x != '', groupArray(msclkid)) msclkid,
arrayFilter(x -> x != '', groupArray(ttclid)) ttclid,
arrayFilter(x -> x != '', groupArray(li_fat_id)) li_fat_id,
arrayFilter(x -> x != '', groupArray(twclid)) twclid,
event_type,
if(event_type = 2, groupArray(event_name), []) event_name,
sumIf(1, event_type = 1) views,
@ -201,6 +218,10 @@ SELECT website_id, session_id, visit_id, event_id, hostname, browser, os, device
page_title,
extract(url_query, 'gclid=([^&]*)') gclid,
extract(url_query, 'fbclid=([^&]*)') fbclid,
extract(url_query, 'msclkid=([^&]*)') msclkid,
extract(url_query, 'ttclid=([^&]*)') ttclid,
extract(url_query, 'li_fat_id=([^&]*)') li_fat_id,
extract(url_query, 'twclid=([^&]*)') twclid,
event_type, event_name, tag, created_at, job_id
FROM umami.website_event
@ -246,6 +267,10 @@ SELECT
page_title,
gclid,
fbclid,
msclkid,
ttclid,
li_fat_id,
twclid,
event_type,
event_name,
views,
@ -279,6 +304,10 @@ FROM (SELECT
arrayFilter(x -> x != '', groupArray(page_title)) page_title,
arrayFilter(x -> x != '', groupArray(gclid)) gclid,
arrayFilter(x -> x != '', groupArray(fbclid)) fbclid,
arrayFilter(x -> x != '', groupArray(msclkid)) msclkid,
arrayFilter(x -> x != '', groupArray(ttclid)) ttclid,
arrayFilter(x -> x != '', groupArray(li_fat_id)) li_fat_id,
arrayFilter(x -> x != '', groupArray(twclid)) twclid,
event_type,
if(event_type = 2, groupArray(event_name), []) event_name,
sumIf(1, event_type = 1) views,

View file

@ -28,8 +28,13 @@ CREATE TABLE umami.website_event
referrer_query String,
referrer_domain String,
page_title String,
--clickIDs
gclid String,
fbclid String,
msclkid String,
ttclid String,
li_fat_id String,
twclid String,
--events
event_type UInt32,
event_name String,
@ -106,6 +111,10 @@ CREATE TABLE umami.website_event_stats_hourly
page_title SimpleAggregateFunction(groupArrayArray, Array(String)),
gclid SimpleAggregateFunction(groupArrayArray, Array(String)),
fbclid SimpleAggregateFunction(groupArrayArray, Array(String)),
msclkid SimpleAggregateFunction(groupArrayArray, Array(String)),
ttclid SimpleAggregateFunction(groupArrayArray, Array(String)),
li_fat_id SimpleAggregateFunction(groupArrayArray, Array(String)),
twclid SimpleAggregateFunction(groupArrayArray, Array(String)),
event_type UInt32,
event_name SimpleAggregateFunction(groupArrayArray, Array(String)),
views SimpleAggregateFunction(sum, UInt64),
@ -154,6 +163,10 @@ SELECT
page_title,
gclid,
fbclid,
msclkid,
ttclid,
li_fat_id,
twclid,
event_type,
event_name,
views,
@ -187,6 +200,10 @@ FROM (SELECT
arrayFilter(x -> x != '', groupArray(page_title)) page_title,
arrayFilter(x -> x != '', groupArray(gclid)) gclid,
arrayFilter(x -> x != '', groupArray(fbclid)) fbclid,
arrayFilter(x -> x != '', groupArray(msclkid)) msclkid,
arrayFilter(x -> x != '', groupArray(ttclid)) ttclid,
arrayFilter(x -> x != '', groupArray(li_fat_id)) li_fat_id,
arrayFilter(x -> x != '', groupArray(twclid)) twclid,
event_type,
if(event_type = 2, groupArray(event_name), []) event_name,
sumIf(1, event_type = 1) views,

View file

@ -13,6 +13,7 @@ import {
Popup,
PopupTrigger,
SubmitButton,
Toggle,
} from 'react-basics';
import BaseParameters from '../[reportId]/BaseParameters';
import ParameterList from '../[reportId]/ParameterList';
@ -21,6 +22,7 @@ import { ReportContext } from '../[reportId]/Report';
import FunnelStepAddForm from '../funnel/FunnelStepAddForm';
import styles from './AttributionParameters.module.css';
import AttributionStepAddForm from './AttributionStepAddForm';
import useRevenueValues from '@/components/hooks/queries/useRevenueValues';
export function AttributionParameters() {
const { report, runReport, updateReport, isRunning } = useContext(ReportContext);
@ -29,14 +31,32 @@ export function AttributionParameters() {
const { websiteId, dateRange, steps } = parameters || {};
const queryEnabled = websiteId && dateRange && steps.length > 0;
const [model, setModel] = useState('');
const [revenueMode, setRevenueMode] = useState(false);
const { data: currencyValues = [] } = useRevenueValues(
websiteId,
dateRange?.startDate,
dateRange?.endDate,
);
const handleSubmit = (data: any, e: any) => {
if (revenueMode === false) {
delete data.currency;
}
e.stopPropagation();
e.preventDefault();
runReport(data);
};
const handleCheck = () => {
setRevenueMode(!revenueMode);
};
const handleAddStep = (step: { type: string; value: string }) => {
if (step.type === 'url') {
setRevenueMode(false);
}
updateReport({ parameters: { steps: parameters.steps.concat(step) } });
};
@ -45,6 +65,9 @@ export function AttributionParameters() {
index: number,
step: { type: string; value: string },
) => {
if (step.type === 'url') {
setRevenueMode(false);
}
const steps = [...parameters.steps];
steps[index] = step;
updateReport({ parameters: { steps } });
@ -135,6 +158,24 @@ export function AttributionParameters() {
})}
</ParameterList>
</FormRow>
<FormRow>
<Toggle
checked={revenueMode}
onChecked={handleCheck}
disabled={currencyValues.length === 0 || steps[0]?.type === 'url'}
>
<b>Revenue Mode</b>
</Toggle>
</FormRow>
{revenueMode && (
<FormRow label={formatMessage(labels.currency)}>
<FormInput name="currency" rules={{ required: formatMessage(labels.required) }}>
<Dropdown items={currencyValues.map(item => item.currency)}>
{item => <Item key={item}>{item}</Item>}
</Dropdown>
</FormInput>
</FormRow>
)}
<FormButtons>
<SubmitButton variant="primary" disabled={!queryEnabled} isLoading={isRunning}>
{formatMessage(labels.runQuery)}

View file

@ -4,8 +4,17 @@
margin-bottom: 40px;
}
.row {
display: flex;
align-items: center;
gap: 10px;
.title {
font-size: 24px;
line-height: 36px;
font-weight: 700;
}
.row {
display: grid;
grid-template-columns: 50% 50%;
gap: 20px;
border-top: 1px solid var(--base300);
padding-top: 30px;
margin-bottom: 30px;
}

View file

@ -1,19 +1,13 @@
import classNames from 'classnames';
import { colord } from 'colord';
import BarChart from '@/components/charts/BarChart';
import PieChart from '@/components/charts/PieChart';
import TypeIcon from '@/components/common/TypeIcon';
import { useCountryNames, useLocale, useMessages } from '@/components/hooks';
import { GridRow } from '@/components/layout/Grid';
import { useMessages } from '@/components/hooks';
import { Grid, GridRow } from '@/components/layout/Grid';
import ListTable from '@/components/metrics/ListTable';
import MetricCard from '@/components/metrics/MetricCard';
import MetricsBar from '@/components/metrics/MetricsBar';
import { renderDateLabels } from '@/lib/charts';
import { CHART_COLORS } from '@/lib/constants';
import { formatLongCurrency, formatLongNumber } from '@/lib/format';
import { useCallback, useContext, useMemo } from 'react';
import { formatLongNumber } from '@/lib/format';
import { useContext } from 'react';
import { ReportContext } from '../[reportId]/Report';
import AttributionTable from './AttributionTable';
import styles from './AttributionView.module.css';
export interface AttributionViewProps {
@ -22,134 +16,118 @@ export interface AttributionViewProps {
export function AttributionView({ isLoading }: AttributionViewProps) {
const { formatMessage, labels } = useMessages();
const { locale } = useLocale();
const { countryNames } = useCountryNames(locale);
const { report } = useContext(ReportContext);
const {
data,
parameters: { dateRange, currency },
parameters: { currency },
} = report || {};
const showTable = data?.table.length > 1;
const ATTRIBUTION_PARAMS = [
{ value: 'referrer', label: formatMessage(labels.referrers) },
{ value: 'paidAds', label: formatMessage(labels.paidAds) },
];
const renderCountryName = useCallback(
({ x: code }) => (
<span className={classNames(locale, styles.row)}>
<TypeIcon type="country" value={code?.toLowerCase()} />
{countryNames[code]}
</span>
),
[countryNames, locale],
);
if (!data) {
return null;
}
const chartData = useMemo(() => {
if (!data) return [];
const { pageviews, visitors, visits } = data.total;
const map = (data.chart as any[]).reduce((obj, { x, t, y }) => {
if (!obj[x]) {
obj[x] = [];
}
const metrics = data
? [
{
value: pageviews,
label: formatMessage(labels.views),
formatValue: formatLongNumber,
},
{
value: visits,
label: formatMessage(labels.visits),
formatValue: formatLongNumber,
},
{
value: visitors,
label: formatMessage(labels.visitors),
formatValue: formatLongNumber,
},
]
: [];
obj[x].push({ x: t, y });
function UTMTable(UTMTableProps: { data: any; title: string; utm: string }) {
const { data, title, utm } = UTMTableProps;
const total = data[utm].reduce((sum, { value }) => {
return +sum + +value;
}, 0);
return obj;
}, {});
return {
datasets: Object.keys(map).map((key, index) => {
const color = colord(CHART_COLORS[index % CHART_COLORS.length]);
return {
label: key,
data: map[key],
lineTension: 0,
backgroundColor: color.alpha(0.6).toRgbString(),
borderColor: color.alpha(0.7).toRgbString(),
borderWidth: 1,
};
}),
};
}, [data]);
const countryData = useMemo(() => {
if (!data) return [];
const labels = data.country.map(({ name }) => name);
const datasets = [
{
data: data.country.map(({ value }) => value),
backgroundColor: CHART_COLORS,
borderWidth: 0,
},
];
return { labels, datasets };
}, [data]);
const metricData = useMemo(() => {
if (!data) return [];
const { sum, count, unique_count } = data.total;
return [
{
value: sum,
label: formatMessage(labels.total),
formatValue: n => formatLongCurrency(n, currency),
},
{
value: count ? sum / count : 0,
label: formatMessage(labels.average),
formatValue: n => formatLongCurrency(n, currency),
},
{
value: count,
label: formatMessage(labels.transactions),
formatValue: formatLongNumber,
},
{
value: unique_count,
label: formatMessage(labels.uniqueCustomers),
formatValue: formatLongNumber,
},
] as any;
}, [data, locale]);
return (
<ListTable
title={title}
metric={formatMessage(currency ? labels.revenue : labels.visitors)}
currency={currency}
data={data[utm].map(({ name, value }) => ({
x: name,
y: Number(value),
z: (value / total) * 100,
}))}
/>
);
}
return (
<>
<div className={styles.container}>
<MetricsBar isFetched={data}>
{metricData?.map(({ label, value, formatValue }) => {
return <MetricCard key={label} value={value} label={label} formatValue={formatValue} />;
})}
</MetricsBar>
{data && (
<>
<BarChart
minDate={dateRange?.startDate}
maxDate={dateRange?.endDate}
data={chartData}
unit={dateRange?.unit}
stacked={true}
currency={currency}
renderXLabel={renderDateLabels(dateRange?.unit, locale)}
isLoading={isLoading}
/>
<GridRow columns="two">
<div className={styles.container}>
<MetricsBar isFetched={data}>
{metrics?.map(({ label, value, formatValue }) => {
return <MetricCard key={label} value={value} label={label} formatValue={formatValue} />;
})}
</MetricsBar>
{ATTRIBUTION_PARAMS.map(({ value, label }) => {
const items = data[value];
const total = items.reduce((sum, { value }) => {
return +sum + +value;
}, 0);
const chartData = {
labels: items.map(({ name }) => name),
datasets: [
{
data: items.map(({ value }) => value),
backgroundColor: CHART_COLORS,
borderWidth: 0,
},
],
};
return (
<div key={value} className={styles.row}>
<div>
<div className={styles.title}>{label}</div>
<ListTable
metric={formatMessage(labels.country)}
data={data?.country.map(({ name, value }) => ({
metric={formatMessage(currency ? labels.revenue : labels.visitors)}
currency={currency}
data={items.map(({ name, value }) => ({
x: name,
y: Number(value),
z: (value / data?.total.sum) * 100,
z: (value / total) * 100,
}))}
renderLabel={renderCountryName}
/>
<PieChart type="doughnut" data={countryData} />
</GridRow>
</>
)}
{showTable && <AttributionTable />}
</div>
</>
</div>
<div>
<PieChart type="doughnut" data={chartData} isLoading={isLoading} />
</div>
</div>
);
})}
<Grid>
<GridRow columns="two">
<UTMTable data={data} title={formatMessage(labels.sources)} utm={'utm_source'} />
<UTMTable data={data} title={formatMessage(labels.medium)} utm={'utm_medium'} />
</GridRow>
<GridRow columns="three">
<UTMTable data={data} title={formatMessage(labels.campaigns)} utm={'utm_campaign'} />
<UTMTable data={data} title={formatMessage(labels.content)} utm={'utm_content'} />
<UTMTable data={data} title={formatMessage(labels.terms)} utm={'utm_term'} />
</GridRow>
</Grid>
</div>
);
}

View file

@ -1,14 +1,14 @@
import { z } from 'zod';
import { canViewWebsite } from '@/lib/auth';
import { unauthorized, json } from '@/lib/response';
import { parseRequest } from '@/lib/request';
import { getFunnel } from '@/queries';
import { json, unauthorized } from '@/lib/response';
import { reportParms } from '@/lib/schema';
import { getAttribution } from '@/queries/sql/reports/getAttribution';
import { z } from 'zod';
export async function POST(request: Request) {
const schema = z.object({
...reportParms,
window: z.coerce.number().positive(),
model: z.string().regex(/firstClick|lastClick/i),
steps: z
.array(
z.object({
@ -16,7 +16,8 @@ export async function POST(request: Request) {
value: z.string(),
}),
)
.min(2),
.min(1),
currency: z.string().optional(),
});
const { auth, body, error } = await parseRequest(request, schema);
@ -27,8 +28,9 @@ export async function POST(request: Request) {
const {
websiteId,
model,
steps,
window,
currency,
dateRange: { startDate, endDate },
} = body;
@ -36,11 +38,12 @@ export async function POST(request: Request) {
return unauthorized();
}
const data = await getFunnel(websiteId, {
const data = await getAttribution(websiteId, {
startDate: new Date(startDate),
endDate: new Date(endDate),
model: model,
steps,
windowMinutes: +window,
currency,
});
return json(data);

View file

@ -288,6 +288,11 @@ export const labels = defineMessages({
firstSeen: { id: 'label.first-seen', defaultMessage: 'First seen' },
properties: { id: 'label.properties', defaultMessage: 'Properties' },
channels: { id: 'label.channels', defaultMessage: 'Channels' },
sources: { id: 'label.sources', defaultMessage: 'Sources' },
medium: { id: 'label.medium', defaultMessage: 'Medium' },
campaigns: { id: 'label.campaigns', defaultMessage: 'Campaigns' },
content: { id: 'label.content', defaultMessage: 'Content' },
terms: { id: 'label.terms', defaultMessage: 'Terms' },
direct: { id: 'label.direct', defaultMessage: 'Direct' },
referral: { id: 'label.referral', defaultMessage: 'Referral' },
affiliate: { id: 'label.affiliate', defaultMessage: 'Affiliate' },

View file

@ -1,11 +1,11 @@
import { FixedSizeList } from 'react-window';
import { useSpring, animated, config } from '@react-spring/web';
import classNames from 'classnames';
import Empty from '@/components/common/Empty';
import { formatLongNumber } from '@/lib/format';
import { useMessages } from '@/components/hooks';
import styles from './ListTable.module.css';
import { formatLongCurrency, formatLongNumber } from '@/lib/format';
import { animated, config, useSpring } from '@react-spring/web';
import classNames from 'classnames';
import { ReactNode } from 'react';
import { FixedSizeList } from 'react-window';
import styles from './ListTable.module.css';
const ITEM_SIZE = 30;
@ -20,6 +20,7 @@ export interface ListTableProps {
virtualize?: boolean;
showPercentage?: boolean;
itemCount?: number;
currency?: string;
}
export function ListTable({
@ -33,6 +34,7 @@ export function ListTable({
virtualize = false,
showPercentage = true,
itemCount = 10,
currency,
}: ListTableProps) {
const { formatMessage, labels } = useMessages();
@ -48,6 +50,7 @@ export function ListTable({
animate={animate && !virtualize}
showPercentage={showPercentage}
change={renderChange ? renderChange(row, index) : null}
currency={currency}
/>
);
};
@ -81,7 +84,15 @@ export function ListTable({
);
}
const AnimatedRow = ({ label, value = 0, percent, change, animate, showPercentage = true }) => {
const AnimatedRow = ({
label,
value = 0,
percent,
change,
animate,
showPercentage = true,
currency,
}) => {
const props = useSpring({
width: percent,
y: value,
@ -95,7 +106,9 @@ const AnimatedRow = ({ label, value = 0, percent, change, animate, showPercentag
<div className={styles.value}>
{change}
<animated.div className={styles.value} title={props?.y as any}>
{props.y?.to(formatLongNumber)}
{currency
? props.y?.to(n => formatLongCurrency(n, currency))
: props.y?.to(formatLongNumber)}
</animated.div>
</div>
{showPercentage && (

View file

@ -1,34 +1,17 @@
import clickhouse from '@/lib/clickhouse';
import { EVENT_TYPE } from '@/lib/constants';
import { CLICKHOUSE, PRISMA, runQuery } from '@/lib/db';
import prisma from '@/lib/prisma';
const formatResults = (steps: { type: string; value: string }[]) => (results: unknown) => {
return steps.map((step: { type: string; value: string }, i: number) => {
const visitors = Number(results[i]?.count) || 0;
const previous = Number(results[i - 1]?.count) || 0;
const dropped = previous > 0 ? previous - visitors : 0;
const dropoff = 1 - visitors / previous;
const remaining = visitors / Number(results[0].count);
return {
...step,
visitors,
previous,
dropped,
dropoff,
remaining,
};
});
};
export async function getFunnel(
export async function getAttribution(
...args: [
websiteId: string,
criteria: {
windowMinutes: number;
startDate: Date;
endDate: Date;
model: string;
steps: { type: string; value: string }[];
currency: string;
},
]
) {
@ -41,210 +24,452 @@ export async function getFunnel(
async function relationalQuery(
websiteId: string,
criteria: {
windowMinutes: number;
startDate: Date;
endDate: Date;
model: string;
steps: { type: string; value: string }[];
currency: string;
},
): Promise<
{
value: string;
visitors: number;
dropoff: number;
}[]
> {
const { windowMinutes, startDate, endDate, steps } = criteria;
const { rawQuery, getAddIntervalQuery } = prisma;
const { levelOneQuery, levelQuery, sumQuery, params } = getFunnelQuery(steps, windowMinutes);
): Promise<{
referrer: { name: string; value: number }[];
paidAds: { name: string; value: number }[];
utm_source: { name: string; value: number }[];
utm_medium: { name: string; value: number }[];
utm_campaign: { name: string; value: number }[];
utm_content: { name: string; value: number }[];
utm_term: { name: string; value: number }[];
total: { pageviews: number; visitors: number; visits: number };
}> {
const { startDate, endDate, model, steps, currency } = criteria;
const { rawQuery } = prisma;
const conversionStep = steps[0].value;
const eventType = steps[0].type === 'url' ? EVENT_TYPE.pageView : EVENT_TYPE.customEvent;
const column = steps[0].type === 'url' ? 'url_path' : 'event_name';
//const db = getDatabaseType();
//const like = db === POSTGRESQL ? 'ilike' : 'like';
function getFunnelQuery(
steps: { type: string; value: string }[],
windowMinutes: number,
): {
levelOneQuery: string;
levelQuery: string;
sumQuery: string;
params: string[];
} {
return steps.reduce(
(pv, cv, i) => {
const levelNumber = i + 1;
const startSum = i > 0 ? 'union ' : '';
const isURL = cv.type === 'url';
const column = isURL ? 'url_path' : 'event_name';
let operator = '=';
let paramValue = cv.value;
if (cv.value.startsWith('*') || cv.value.endsWith('*')) {
operator = 'like';
paramValue = cv.value.replace(/^\*|\*$/g, '%');
}
if (levelNumber === 1) {
pv.levelOneQuery = `
WITH level1 AS (
select distinct session_id, created_at
from website_event
where website_id = {{websiteId::uuid}}
and created_at between {{startDate}} and {{endDate}}
and ${column} ${operator} {{${i}}}
)`;
} else {
pv.levelQuery += `
, level${levelNumber} AS (
select distinct we.session_id, we.created_at
from level${i} l
join website_event we
on l.session_id = we.session_id
where we.website_id = {{websiteId::uuid}}
and we.created_at between l.created_at and ${getAddIntervalQuery(
`l.created_at `,
`${windowMinutes} minute`,
)}
and we.${column} ${operator} {{${i}}}
and we.created_at <= {{endDate}}
)`;
}
pv.sumQuery += `\n${startSum}select ${levelNumber} as level, count(distinct(session_id)) as count from level${levelNumber}`;
pv.params.push(paramValue);
return pv;
},
{
levelOneQuery: '',
levelQuery: '',
sumQuery: '',
params: [],
},
);
function getUTMQuery(utmColumn: string) {
return `
select
we.${utmColumn} name,
${currency ? 'sum(e.value)' : 'uniqExact(we.session_id)'} value
from events e
join model m
on m.session_id = e.session_id
join website_event we
on we.created_at = m.created_at
and we.session_id = m.session_id
${currency ? '' : `where we.${utmColumn} != ''`}
group by 1
order by name desc
limit 20`;
}
return rawQuery(
const eventQuery = `WITH events AS (
select distinct
session_id,
max(created_at) max_dt
from website_event
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and ${column} = {conversionStep:String}
and event_type = {eventType:UInt32}
group by 1),`;
const revenueEventQuery = `WITH events AS (
select
ed.session_id,
max(ed.created_at) max_dt,
sum(coalesce(toDecimal64(number_value, 2), toDecimal64(string_value, 2))) as value
from event_data ed
join (select event_id
from event_data
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and positionCaseInsensitive(data_key, 'currency') > 0
and string_value = {currency:String}) c
on c.event_id = ed.event_id
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and ${column} = {conversionStep:String}
and positionCaseInsensitive(ed.data_key, 'revenue') > 0
group by 1),`;
function getModelQuery(model: string) {
return model === 'firstClick'
? `\n
model AS (select e.session_id,
min(we.created_at) created_at
from events e
join website_event we
on we.session_id = e.session_id
group by e.session_id)`
: `\n
model AS (select e.session_id,
max(we.created_at) created_at
from events e
join website_event we
on we.session_id = e.session_id
where we.created_at < e.max_dt
group by e.session_id)`;
}
const referrerRes = await rawQuery(
`
${levelOneQuery}
${levelQuery}
${sumQuery}
ORDER BY level;
${currency ? revenueEventQuery : eventQuery}
${getModelQuery(model)}
select we.referrer_domain name,
${currency ? 'sum(e.value)' : 'uniqExact(we.session_id)'} value
from events e
join model m
on m.session_id = e.session_id
join website_event we
on we.created_at = m.created_at
and we.session_id = m.session_id
${
currency
? ''
: `where referrer_domain != hostname
and we.referrer_domain != ''`
}
group by 1
order by 2 desc
limit 20
`,
{
websiteId,
startDate,
endDate,
...params,
},
).then(formatResults(steps));
{ websiteId, startDate, endDate, conversionStep, eventType, currency },
);
const paidAdsres = await rawQuery(
`
${currency ? revenueEventQuery : eventQuery}
${getModelQuery(model)}
select multiIf(gclid != '', 'Google', fbclid != '', 'Facebook', '') name,
${currency ? 'sum(e.value)' : 'uniqExact(we.session_id)'} value
from events e
join model m
on m.session_id = e.session_id
join website_event we
on we.created_at = m.created_at
and we.session_id = m.session_id
${currency ? '' : `WHERE name != ''`}
group by 1
order by 2 desc
limit 20
`,
{ websiteId, startDate, endDate, conversionStep, eventType, currency },
);
const sourceRes = await rawQuery(
`
${currency ? revenueEventQuery : eventQuery}
${getModelQuery(model)}
${getUTMQuery('utm_source')}
`,
{ websiteId, startDate, endDate, conversionStep, eventType, currency },
);
const mediumRes = await rawQuery(
`
${currency ? revenueEventQuery : eventQuery}
${getModelQuery(model)}
${getUTMQuery('utm_medium')}
`,
{ websiteId, startDate, endDate, conversionStep, eventType, currency },
);
const campaignRes = await rawQuery(
`
${currency ? revenueEventQuery : eventQuery}
${getModelQuery(model)}
${getUTMQuery('utm_campaign')}
`,
{ websiteId, startDate, endDate, conversionStep, eventType, currency },
);
const contentRes = await rawQuery(
`
${currency ? revenueEventQuery : eventQuery}
${getModelQuery(model)}
${getUTMQuery('utm_content')}
`,
{ websiteId, startDate, endDate, conversionStep, eventType, currency },
);
const termRes = await rawQuery(
`
${currency ? revenueEventQuery : eventQuery}
${getModelQuery(model)}
${getUTMQuery('utm_term')}
`,
{ websiteId, startDate, endDate, conversionStep, eventType, currency },
);
const totalRes = await rawQuery(
`
select
count(*) as "pageviews",
uniqExact(session_id) as "visitors",
uniqExact(visit_id) as "visits"
from website_event
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and ${column} = {conversionStep:String}
and event_type = {eventType:UInt32}
`,
{ websiteId, startDate, endDate, conversionStep, eventType, currency },
).then(result => result?.[0]);
return {
referrer: referrerRes,
paidAds: paidAdsres,
utm_source: sourceRes,
utm_medium: mediumRes,
utm_campaign: campaignRes,
utm_content: contentRes,
utm_term: termRes,
total: totalRes,
};
}
async function clickhouseQuery(
websiteId: string,
criteria: {
windowMinutes: number;
startDate: Date;
endDate: Date;
model: string;
steps: { type: string; value: string }[];
currency: string;
},
): Promise<
{
value: string;
visitors: number;
dropoff: number;
}[]
> {
const { windowMinutes, startDate, endDate, steps } = criteria;
): Promise<{
referrer: { name: string; value: number }[];
paidAds: { name: string; value: number }[];
utm_source: { name: string; value: number }[];
utm_medium: { name: string; value: number }[];
utm_campaign: { name: string; value: number }[];
utm_content: { name: string; value: number }[];
utm_term: { name: string; value: number }[];
total: { pageviews: number; visitors: number; visits: number };
}> {
const { startDate, endDate, model, steps, currency } = criteria;
const { rawQuery } = clickhouse;
const { levelOneQuery, levelQuery, sumQuery, stepFilterQuery, params } = getFunnelQuery(
steps,
windowMinutes,
);
const conversionStep = steps[0].value;
const eventType = steps[0].type === 'url' ? EVENT_TYPE.pageView : EVENT_TYPE.customEvent;
const column = steps[0].type === 'url' ? 'url_path' : 'event_name';
function getFunnelQuery(
steps: { type: string; value: string }[],
windowMinutes: number,
): {
levelOneQuery: string;
levelQuery: string;
sumQuery: string;
stepFilterQuery: string;
params: { [key: string]: string };
} {
return steps.reduce(
(pv, cv, i) => {
const levelNumber = i + 1;
const startSum = i > 0 ? 'union all ' : '';
const startFilter = i > 0 ? 'or' : '';
const isURL = cv.type === 'url';
const column = isURL ? 'url_path' : 'event_name';
let operator = '=';
let paramValue = cv.value;
if (cv.value.startsWith('*') || cv.value.endsWith('*')) {
operator = 'like';
paramValue = cv.value.replace(/^\*|\*$/g, '%');
}
if (levelNumber === 1) {
pv.levelOneQuery = `\n
level1 AS (
select *
from level0
where ${column} ${operator} {param${i}:String}
)`;
} else {
pv.levelQuery += `\n
, level${levelNumber} AS (
select distinct y.session_id as session_id,
y.url_path as url_path,
y.referrer_path as referrer_path,
y.event_name,
y.created_at as created_at
from level${i} x
join level0 y
on x.session_id = y.session_id
where y.created_at between x.created_at and x.created_at + interval ${windowMinutes} minute
and y.${column} ${operator} {param${i}:String}
)`;
}
pv.sumQuery += `\n${startSum}select ${levelNumber} as level, count(distinct(session_id)) as count from level${levelNumber}`;
pv.stepFilterQuery += `${startFilter} ${column} ${operator} {param${i}:String} `;
pv.params[`param${i}`] = paramValue;
return pv;
},
{
levelOneQuery: '',
levelQuery: '',
sumQuery: '',
stepFilterQuery: '',
params: {},
},
);
function getUTMQuery(utmColumn: string) {
return `
select
we.${utmColumn} name,
${currency ? 'sum(e.value)' : 'uniqExact(we.session_id)'} value
from events e
join model m
on m.session_id = e.session_id
join website_event we
on we.created_at = m.created_at
and we.session_id = m.session_id
${currency ? '' : `where we.${utmColumn} != ''`}
group by 1
order by name desc
limit 20`;
}
return rawQuery(
`
WITH level0 AS (
select distinct session_id, url_path, referrer_path, event_name, created_at
from umami.website_event
where (${stepFilterQuery})
and website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
),
${levelOneQuery}
${levelQuery}
select *
from (
${sumQuery}
) ORDER BY level;
`,
const eventQuery = `WITH events AS (
select distinct
session_id,
max(created_at) max_dt
from website_event
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and ${column} = {conversionStep:String}
and event_type = {eventType:UInt32}
group by 1),`;
const revenueEventQuery = `WITH events AS (
select
ed.session_id,
max(ed.created_at) max_dt,
sum(coalesce(toDecimal64(number_value, 2), toDecimal64(string_value, 2))) as value
from event_data ed
join (select event_id
from event_data
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and positionCaseInsensitive(data_key, 'currency') > 0
and string_value = {currency:String}) c
on c.event_id = ed.event_id
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and ${column} = {conversionStep:String}
and positionCaseInsensitive(ed.data_key, 'revenue') > 0
group by 1),`;
function getModelQuery(model: string) {
return model === 'firstClick'
? `\n
model AS (select e.session_id,
min(we.created_at) created_at
from events e
join website_event we
on we.session_id = e.session_id
group by e.session_id)`
: `\n
model AS (select e.session_id,
max(we.created_at) created_at
from events e
join website_event we
on we.session_id = e.session_id
where we.created_at < e.max_dt
group by e.session_id)`;
}
const referrerRes = await rawQuery<
{
websiteId,
startDate,
endDate,
...params,
},
).then(formatResults(steps));
name: string;
value: number;
}[]
>(
`
${currency ? revenueEventQuery : eventQuery}
${getModelQuery(model)}
select we.referrer_domain name,
${currency ? 'sum(e.value)' : 'uniqExact(we.session_id)'} value
from events e
join model m
on m.session_id = e.session_id
join website_event we
on we.created_at = m.created_at
and we.session_id = m.session_id
${
currency
? ''
: `where referrer_domain != hostname
and we.referrer_domain != ''`
}
group by 1
order by 2 desc
limit 20
`,
{ websiteId, startDate, endDate, conversionStep, eventType, currency },
);
const paidAdsres = await rawQuery<
{
name: string;
value: number;
}[]
>(
`
${currency ? revenueEventQuery : eventQuery}
${getModelQuery(model)}
select multiIf(gclid != '', 'Google', fbclid != '', 'Facebook', '') name,
${currency ? 'sum(e.value)' : 'uniqExact(we.session_id)'} value
from events e
join model m
on m.session_id = e.session_id
join website_event we
on we.created_at = m.created_at
and we.session_id = m.session_id
${currency ? '' : `WHERE name != ''`}
group by 1
order by 2 desc
limit 20
`,
{ websiteId, startDate, endDate, conversionStep, eventType, currency },
);
const sourceRes = await rawQuery<
{
name: string;
value: number;
}[]
>(
`
${currency ? revenueEventQuery : eventQuery}
${getModelQuery(model)}
${getUTMQuery('utm_source')}
`,
{ websiteId, startDate, endDate, conversionStep, eventType, currency },
);
const mediumRes = await rawQuery<
{
name: string;
value: number;
}[]
>(
`
${currency ? revenueEventQuery : eventQuery}
${getModelQuery(model)}
${getUTMQuery('utm_medium')}
`,
{ websiteId, startDate, endDate, conversionStep, eventType, currency },
);
const campaignRes = await rawQuery<
{
name: string;
value: number;
}[]
>(
`
${currency ? revenueEventQuery : eventQuery}
${getModelQuery(model)}
${getUTMQuery('utm_campaign')}
`,
{ websiteId, startDate, endDate, conversionStep, eventType, currency },
);
const contentRes = await rawQuery<
{
name: string;
value: number;
}[]
>(
`
${currency ? revenueEventQuery : eventQuery}
${getModelQuery(model)}
${getUTMQuery('utm_content')}
`,
{ websiteId, startDate, endDate, conversionStep, eventType, currency },
);
const termRes = await rawQuery<
{
name: string;
value: number;
}[]
>(
`
${currency ? revenueEventQuery : eventQuery}
${getModelQuery(model)}
${getUTMQuery('utm_term')}
`,
{ websiteId, startDate, endDate, conversionStep, eventType, currency },
);
const totalRes = await rawQuery<{ pageviews: number; visitors: number; visits: number }>(
`
select
count(*) as "pageviews",
uniqExact(session_id) as "visitors",
uniqExact(visit_id) as "visits"
from website_event
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and ${column} = {conversionStep:String}
and event_type = {eventType:UInt32}
`,
{ websiteId, startDate, endDate, conversionStep, eventType, currency },
).then(result => result?.[0]);
return {
referrer: referrerRes,
paidAds: paidAdsres,
utm_source: sourceRes,
utm_medium: mediumRes,
utm_campaign: campaignRes,
utm_content: contentRes,
utm_term: termRes,
total: totalRes,
};
}

View file

@ -56,7 +56,9 @@ async function relationalQuery(
on we.event_id = ed.website_event_id
join (select website_event_id
from event_data
where data_key ${like} '%currency%'
where website_id = {{websiteId::uuid}}
and created_at between {{startDate}} and {{endDate}}
and data_key ${like} '%currency%'
and string_value = {{currency}}) currency
on currency.website_event_id = ed.website_event_id
where ed.website_id = {{websiteId::uuid}}
@ -80,7 +82,9 @@ async function relationalQuery(
on s.session_id = we.session_id
join (select website_event_id
from event_data
where data_key ${like} '%currency%'
where website_id = {{websiteId::uuid}}
and created_at between {{startDate}} and {{endDate}}
and data_key ${like} '%currency%'
and string_value = {{currency}}) currency
on currency.website_event_id = ed.website_event_id
where ed.website_id = {{websiteId::uuid}}
@ -102,7 +106,9 @@ async function relationalQuery(
on we.event_id = ed.website_event_id
join (select website_event_id
from event_data
where data_key ${like} '%currency%'
where website_id = {{websiteId::uuid}}
and created_at between {{startDate}} and {{endDate}}
and data_key ${like} '%currency%'
and string_value = {{currency}}) currency
on currency.website_event_id = ed.website_event_id
where ed.website_id = {{websiteId::uuid}}
@ -124,7 +130,9 @@ async function relationalQuery(
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
where website_id = {{websiteId::uuid}}
and created_at between {{startDate}} and {{endDate}}
and 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}}
@ -176,7 +184,9 @@ async function clickhouseQuery(
from event_data
join (select event_id
from event_data
where positionCaseInsensitive(data_key, 'currency') > 0
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and positionCaseInsensitive(data_key, 'currency') > 0
and string_value = {currency:String}) currency
on currency.event_id = event_data.event_id
where website_id = {websiteId:UUID}
@ -201,7 +211,9 @@ async function clickhouseQuery(
from event_data ed
join (select event_id
from event_data
where positionCaseInsensitive(data_key, 'currency') > 0
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and 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
@ -231,7 +243,9 @@ async function clickhouseQuery(
from event_data
join (select event_id
from event_data
where positionCaseInsensitive(data_key, 'currency') > 0
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and positionCaseInsensitive(data_key, 'currency') > 0
and string_value = {currency:String}) currency
on currency.event_id = event_data.event_id
where website_id = {websiteId:UUID}
@ -259,7 +273,9 @@ async function clickhouseQuery(
from event_data ed
join (select event_id, string_value as currency
from event_data
where positionCaseInsensitive(data_key, 'currency') > 0) c
where website_id = {websiteId:UUID}
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
and 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}