diff --git a/db/clickhouse/migrations/05_add_utm_clid.sql b/db/clickhouse/migrations/05_add_utm_clid.sql
new file mode 100644
index 00000000..c0ab537a
--- /dev/null
+++ b/db/clickhouse/migrations/05_add_utm_clid.sql
@@ -0,0 +1,332 @@
+-- Create Event
+CREATE TABLE umami.website_event_new
+(
+ website_id UUID,
+ session_id UUID,
+ visit_id UUID,
+ event_id UUID,
+ --sessions
+ hostname LowCardinality(String),
+ browser LowCardinality(String),
+ os LowCardinality(String),
+ device LowCardinality(String),
+ screen LowCardinality(String),
+ language LowCardinality(String),
+ country LowCardinality(String),
+ subdivision1 LowCardinality(String),
+ subdivision2 LowCardinality(String),
+ city String,
+ --pageviews
+ url_path String,
+ url_query String,
+ utm_source String,
+ utm_medium String,
+ utm_campaign String,
+ utm_content String,
+ utm_term String,
+ referrer_path String,
+ 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,
+ tag String,
+ created_at DateTime('UTC'),
+ job_id Nullable(UUID)
+)
+ENGINE = MergeTree
+ PARTITION BY toYYYYMM(created_at)
+ ORDER BY (toStartOfHour(created_at), website_id, session_id, visit_id, created_at)
+ PRIMARY KEY (toStartOfHour(created_at), website_id, session_id, visit_id)
+ SETTINGS index_granularity = 8192;
+
+-- stats hourly
+CREATE TABLE umami.website_event_stats_hourly_new
+(
+ website_id UUID,
+ session_id UUID,
+ visit_id UUID,
+ hostname LowCardinality(String),
+ browser LowCardinality(String),
+ os LowCardinality(String),
+ device LowCardinality(String),
+ screen LowCardinality(String),
+ language LowCardinality(String),
+ country LowCardinality(String),
+ subdivision1 LowCardinality(String),
+ city String,
+ entry_url AggregateFunction(argMin, String, DateTime('UTC')),
+ exit_url AggregateFunction(argMax, String, DateTime('UTC')),
+ url_path SimpleAggregateFunction(groupArrayArray, Array(String)),
+ url_query SimpleAggregateFunction(groupArrayArray, Array(String)),
+ utm_source SimpleAggregateFunction(groupArrayArray, Array(String)),
+ utm_medium SimpleAggregateFunction(groupArrayArray, Array(String)),
+ utm_campaign SimpleAggregateFunction(groupArrayArray, Array(String)),
+ utm_content SimpleAggregateFunction(groupArrayArray, Array(String)),
+ utm_term SimpleAggregateFunction(groupArrayArray, Array(String)),
+ referrer_domain SimpleAggregateFunction(groupArrayArray, Array(String)),
+ 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),
+ min_time SimpleAggregateFunction(min, DateTime('UTC')),
+ max_time SimpleAggregateFunction(max, DateTime('UTC')),
+ tag SimpleAggregateFunction(groupArrayArray, Array(String)),
+ created_at Datetime('UTC')
+)
+ENGINE = AggregatingMergeTree
+ PARTITION BY toYYYYMM(created_at)
+ ORDER BY (
+ website_id,
+ event_type,
+ toStartOfHour(created_at),
+ cityHash64(visit_id),
+ visit_id
+ )
+ SAMPLE BY cityHash64(visit_id);
+
+CREATE MATERIALIZED VIEW umami.website_event_stats_hourly_mv_new
+TO umami.website_event_stats_hourly_new
+AS
+SELECT
+ website_id,
+ session_id,
+ visit_id,
+ hostname,
+ browser,
+ os,
+ device,
+ screen,
+ language,
+ country,
+ subdivision1,
+ city,
+ entry_url,
+ exit_url,
+ url_paths as url_path,
+ url_query,
+ utm_source,
+ utm_medium,
+ utm_campaign,
+ utm_content,
+ utm_term,
+ referrer_domain,
+ page_title,
+ gclid,
+ fbclid,
+ msclkid,
+ ttclid,
+ li_fat_id,
+ twclid,
+ event_type,
+ event_name,
+ views,
+ min_time,
+ max_time,
+ tag,
+ timestamp as created_at
+FROM (SELECT
+ website_id,
+ session_id,
+ visit_id,
+ hostname,
+ browser,
+ os,
+ device,
+ screen,
+ language,
+ country,
+ subdivision1,
+ city,
+ argMinState(url_path, created_at) entry_url,
+ argMaxState(url_path, created_at) exit_url,
+ arrayFilter(x -> x != '', groupArray(url_path)) as url_paths,
+ arrayFilter(x -> x != '', groupArray(url_query)) url_query,
+ arrayFilter(x -> x != '', groupArray(utm_source)) utm_source,
+ arrayFilter(x -> x != '', groupArray(utm_medium)) utm_medium,
+ arrayFilter(x -> x != '', groupArray(utm_campaign)) utm_campaign,
+ arrayFilter(x -> x != '', groupArray(utm_content)) utm_content,
+ arrayFilter(x -> x != '', groupArray(utm_term)) utm_term,
+ arrayFilter(x -> x != '', groupArray(referrer_domain)) referrer_domain,
+ 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,
+ min(created_at) min_time,
+ max(created_at) max_time,
+ arrayFilter(x -> x != '', groupArray(tag)) tag,
+ toStartOfHour(created_at) timestamp
+FROM umami.website_event_new
+GROUP BY website_id,
+ session_id,
+ visit_id,
+ hostname,
+ browser,
+ os,
+ device,
+ screen,
+ language,
+ country,
+ subdivision1,
+ city,
+ event_type,
+ timestamp);
+
+-- projections
+ALTER TABLE umami.website_event_new
+ADD PROJECTION website_event_url_path_projection (
+SELECT * ORDER BY toStartOfDay(created_at), website_id, url_path, created_at
+);
+
+ALTER TABLE umami.website_event_new MATERIALIZE PROJECTION website_event_url_path_projection_new;
+
+ALTER TABLE umami.website_event_new
+ADD PROJECTION website_event_referrer_domain_projection (
+SELECT * ORDER BY toStartOfDay(created_at), website_id, referrer_domain, created_at
+);
+
+ALTER TABLE umami.website_event_new MATERIALIZE PROJECTION website_event_referrer_domain_projection;
+
+-- migration
+INSERT INTO umami.website_event_new
+SELECT website_id, session_id, visit_id, event_id, hostname, browser, os, device, screen, language, country, subdivision1, subdivision2, city, url_path, url_query,
+ extract(url_query, 'utm_source=([^&]*)') AS utm_source,
+ extract(url_query, 'utm_medium=([^&]*)') AS utm_medium,
+ extract(url_query, 'utm_campaign=([^&]*)') AS utm_campaign,
+ extract(url_query, 'utm_content=([^&]*)') AS utm_content,
+ extract(url_query, 'utm_term=([^&]*)') AS utm_term,referrer_path, referrer_query, referrer_domain,
+ 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
+
+-- rename tables
+RENAME TABLE umami.website_event TO umami.website_event_old;
+RENAME TABLE umami.website_event_new TO umami.website_event;
+
+RENAME TABLE umami.website_event_stats_hourly TO umami.website_event_stats_hourly_old;
+RENAME TABLE umami.website_event_stats_hourly_new TO umami.website_event_stats_hourly;
+
+RENAME TABLE umami.website_event_stats_hourly_mv TO umami.website_event_stats_hourly_mv_old;
+RENAME TABLE umami.website_event_stats_hourly_mv_new TO umami.website_event_stats_hourly_mv;
+
+-- recreate view
+DROP TABLE umami.website_event_stats_hourly_mv;
+
+CREATE MATERIALIZED VIEW umami.website_event_stats_hourly_mv
+TO umami.website_event_stats_hourly
+AS
+SELECT
+ website_id,
+ session_id,
+ visit_id,
+ hostname,
+ browser,
+ os,
+ device,
+ screen,
+ language,
+ country,
+ subdivision1,
+ city,
+ entry_url,
+ exit_url,
+ url_paths as url_path,
+ url_query,
+ utm_source,
+ utm_medium,
+ utm_campaign,
+ utm_content,
+ utm_term,
+ referrer_domain,
+ page_title,
+ gclid,
+ fbclid,
+ msclkid,
+ ttclid,
+ li_fat_id,
+ twclid,
+ event_type,
+ event_name,
+ views,
+ min_time,
+ max_time,
+ tag,
+ timestamp as created_at
+FROM (SELECT
+ website_id,
+ session_id,
+ visit_id,
+ hostname,
+ browser,
+ os,
+ device,
+ screen,
+ language,
+ country,
+ subdivision1,
+ city,
+ argMinState(url_path, created_at) entry_url,
+ argMaxState(url_path, created_at) exit_url,
+ arrayFilter(x -> x != '', groupArray(url_path)) as url_paths,
+ arrayFilter(x -> x != '', groupArray(url_query)) url_query,
+ arrayFilter(x -> x != '', groupArray(utm_source)) utm_source,
+ arrayFilter(x -> x != '', groupArray(utm_medium)) utm_medium,
+ arrayFilter(x -> x != '', groupArray(utm_campaign)) utm_campaign,
+ arrayFilter(x -> x != '', groupArray(utm_content)) utm_content,
+ arrayFilter(x -> x != '', groupArray(utm_term)) utm_term,
+ arrayFilter(x -> x != '', groupArray(referrer_domain)) referrer_domain,
+ 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,
+ min(created_at) min_time,
+ max(created_at) max_time,
+ arrayFilter(x -> x != '', groupArray(tag)) tag,
+ toStartOfHour(created_at) timestamp
+FROM umami.website_event
+GROUP BY website_id,
+ session_id,
+ visit_id,
+ hostname,
+ browser,
+ os,
+ device,
+ screen,
+ language,
+ country,
+ subdivision1,
+ city,
+ event_type,
+ timestamp);
\ No newline at end of file
diff --git a/db/clickhouse/schema.sql b/db/clickhouse/schema.sql
index 5ceaaa0e..11ab8832 100644
--- a/db/clickhouse/schema.sql
+++ b/db/clickhouse/schema.sql
@@ -19,10 +19,22 @@ CREATE TABLE umami.website_event
--pageviews
url_path String,
url_query String,
+ utm_source String,
+ utm_medium String,
+ utm_campaign String,
+ utm_content String,
+ utm_term String,
referrer_path String,
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,
@@ -90,8 +102,19 @@ CREATE TABLE umami.website_event_stats_hourly
exit_url AggregateFunction(argMax, String, DateTime('UTC')),
url_path SimpleAggregateFunction(groupArrayArray, Array(String)),
url_query SimpleAggregateFunction(groupArrayArray, Array(String)),
+ utm_source SimpleAggregateFunction(groupArrayArray, Array(String)),
+ utm_medium SimpleAggregateFunction(groupArrayArray, Array(String)),
+ utm_campaign SimpleAggregateFunction(groupArrayArray, Array(String)),
+ utm_content SimpleAggregateFunction(groupArrayArray, Array(String)),
+ utm_term SimpleAggregateFunction(groupArrayArray, Array(String)),
referrer_domain SimpleAggregateFunction(groupArrayArray, Array(String)),
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),
@@ -131,8 +154,19 @@ SELECT
exit_url,
url_paths as url_path,
url_query,
+ utm_source,
+ utm_medium,
+ utm_campaign,
+ utm_content,
+ utm_term,
referrer_domain,
page_title,
+ gclid,
+ fbclid,
+ msclkid,
+ ttclid,
+ li_fat_id,
+ twclid,
event_type,
event_name,
views,
@@ -157,8 +191,19 @@ FROM (SELECT
argMaxState(url_path, created_at) exit_url,
arrayFilter(x -> x != '', groupArray(url_path)) as url_paths,
arrayFilter(x -> x != '', groupArray(url_query)) url_query,
+ arrayFilter(x -> x != '', groupArray(utm_source)) utm_source,
+ arrayFilter(x -> x != '', groupArray(utm_medium)) utm_medium,
+ arrayFilter(x -> x != '', groupArray(utm_campaign)) utm_campaign,
+ arrayFilter(x -> x != '', groupArray(utm_content)) utm_content,
+ arrayFilter(x -> x != '', groupArray(utm_term)) utm_term,
arrayFilter(x -> x != '', groupArray(referrer_domain)) referrer_domain,
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,
diff --git a/src/app/(main)/reports/attribution/AttributionParameters.module.css b/src/app/(main)/reports/attribution/AttributionParameters.module.css
new file mode 100644
index 00000000..0f27d515
--- /dev/null
+++ b/src/app/(main)/reports/attribution/AttributionParameters.module.css
@@ -0,0 +1,12 @@
+.item {
+ display: flex;
+ align-items: center;
+ gap: 10px;
+ width: 100%;
+}
+
+.value {
+ display: flex;
+ align-self: center;
+ gap: 20px;
+}
diff --git a/src/app/(main)/reports/attribution/AttributionParameters.tsx b/src/app/(main)/reports/attribution/AttributionParameters.tsx
new file mode 100644
index 00000000..2763273d
--- /dev/null
+++ b/src/app/(main)/reports/attribution/AttributionParameters.tsx
@@ -0,0 +1,188 @@
+import { useMessages } from '@/components/hooks';
+import Icons from '@/components/icons';
+import { useContext, useState } from 'react';
+import {
+ Button,
+ Dropdown,
+ Form,
+ FormButtons,
+ FormInput,
+ FormRow,
+ Icon,
+ Item,
+ Popup,
+ PopupTrigger,
+ SubmitButton,
+ Toggle,
+} from 'react-basics';
+import BaseParameters from '../[reportId]/BaseParameters';
+import ParameterList from '../[reportId]/ParameterList';
+import PopupForm from '../[reportId]/PopupForm';
+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);
+ const { formatMessage, labels } = useMessages();
+ const { id, parameters } = report || {};
+ 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) } });
+ };
+
+ const handleUpdateStep = (
+ close: () => void,
+ index: number,
+ step: { type: string; value: string },
+ ) => {
+ if (step.type === 'url') {
+ setRevenueMode(false);
+ }
+ const steps = [...parameters.steps];
+ steps[index] = step;
+ updateReport({ parameters: { steps } });
+ close();
+ };
+
+ const handleRemoveStep = (index: number) => {
+ const steps = [...parameters.steps];
+ delete steps[index];
+ updateReport({ parameters: { steps: steps.filter(n => n) } });
+ };
+
+ const AddStepButton = () => {
+ return (
+ 0}>
+
+
+
+
+
+
+
+ );
+ };
+
+ const items = [
+ { label: 'First-Click', value: 'firstClick' },
+ { label: 'Last-Click', value: 'lastClick' },
+ ];
+
+ const renderModelValue = (value: any) => {
+ return items.find(item => item.value === value)?.label;
+ };
+
+ const onModelChange = (value: any) => {
+ setModel(value);
+ updateReport({ parameters: { model } });
+ };
+
+ return (
+
+ );
+}
+
+export default AttributionParameters;
diff --git a/src/app/(main)/reports/attribution/AttributionReport.tsx b/src/app/(main)/reports/attribution/AttributionReport.tsx
new file mode 100644
index 00000000..c33a4195
--- /dev/null
+++ b/src/app/(main)/reports/attribution/AttributionReport.tsx
@@ -0,0 +1,27 @@
+import Money from '@/assets/money.svg';
+import { REPORT_TYPES } from '@/lib/constants';
+import Report from '../[reportId]/Report';
+import ReportBody from '../[reportId]/ReportBody';
+import ReportHeader from '../[reportId]/ReportHeader';
+import ReportMenu from '../[reportId]/ReportMenu';
+import AttributionParameters from './AttributionParameters';
+import AttributionView from './AttributionView';
+
+const defaultParameters = {
+ type: REPORT_TYPES.attribution,
+ parameters: { model: 'firstClick', steps: [] },
+};
+
+export default function AttributionReport({ reportId }: { reportId?: string }) {
+ return (
+
+ } />
+
+
+
+
+
+
+
+ );
+}
diff --git a/src/app/(main)/reports/attribution/AttributionReportPage.tsx b/src/app/(main)/reports/attribution/AttributionReportPage.tsx
new file mode 100644
index 00000000..ed730704
--- /dev/null
+++ b/src/app/(main)/reports/attribution/AttributionReportPage.tsx
@@ -0,0 +1,6 @@
+'use client';
+import AttributionReport from './AttributionReport';
+
+export default function AttributionReportPage() {
+ return ;
+}
diff --git a/src/app/(main)/reports/attribution/AttributionStepAddForm.module.css b/src/app/(main)/reports/attribution/AttributionStepAddForm.module.css
new file mode 100644
index 00000000..a254ff08
--- /dev/null
+++ b/src/app/(main)/reports/attribution/AttributionStepAddForm.module.css
@@ -0,0 +1,7 @@
+.dropdown {
+ width: 140px;
+}
+
+.input {
+ width: 200px;
+}
diff --git a/src/app/(main)/reports/attribution/AttributionStepAddForm.tsx b/src/app/(main)/reports/attribution/AttributionStepAddForm.tsx
new file mode 100644
index 00000000..d36b0591
--- /dev/null
+++ b/src/app/(main)/reports/attribution/AttributionStepAddForm.tsx
@@ -0,0 +1,80 @@
+import { useState } from 'react';
+import { useMessages } from '@/components/hooks';
+import { Button, FormRow, TextField, Flexbox, Dropdown, Item } from 'react-basics';
+import styles from './AttributionStepAddForm.module.css';
+
+export interface AttributionStepAddFormProps {
+ type?: string;
+ value?: string;
+ onChange?: (step: { type: string; value: string }) => void;
+}
+
+export function AttributionStepAddForm({
+ type: defaultType = 'url',
+ value: defaultValue = '',
+ onChange,
+}: AttributionStepAddFormProps) {
+ const [type, setType] = useState(defaultType);
+ const [value, setValue] = useState(defaultValue);
+ const { formatMessage, labels } = useMessages();
+ const items = [
+ { label: formatMessage(labels.url), value: 'url' },
+ { label: formatMessage(labels.event), value: 'event' },
+ ];
+ const isDisabled = !type || !value;
+
+ const handleSave = () => {
+ onChange({ type, value });
+ setValue('');
+ };
+
+ const handleChange = e => {
+ setValue(e.target.value);
+ };
+
+ const handleKeyDown = e => {
+ if (e.key === 'Enter') {
+ e.stopPropagation();
+ handleSave();
+ }
+ };
+
+ const renderTypeValue = (value: any) => {
+ return items.find(item => item.value === value)?.label;
+ };
+
+ return (
+
+
+
+ setType(value)}
+ >
+ {({ value, label }) => {
+ return - {label}
;
+ }}
+
+
+
+
+
+
+
+
+ );
+}
+
+export default AttributionStepAddForm;
diff --git a/src/app/(main)/reports/attribution/AttributionTable.tsx b/src/app/(main)/reports/attribution/AttributionTable.tsx
new file mode 100644
index 00000000..84d73b28
--- /dev/null
+++ b/src/app/(main)/reports/attribution/AttributionTable.tsx
@@ -0,0 +1,38 @@
+import EmptyPlaceholder from '@/components/common/EmptyPlaceholder';
+import { useMessages } from '@/components/hooks';
+import { useContext } from 'react';
+import { GridColumn, GridTable } from 'react-basics';
+import { ReportContext } from '../[reportId]/Report';
+import { formatLongCurrency } from '@/lib/format';
+
+export function AttributionTable() {
+ const { report } = useContext(ReportContext);
+ const { formatMessage, labels } = useMessages();
+ const { data } = report || {};
+
+ if (!data) {
+ return ;
+ }
+
+ return (
+
+
+ {row => row.currency}
+
+
+ {row => formatLongCurrency(row.sum, row.currency)}
+
+
+ {row => formatLongCurrency(row.count ? row.sum / row.count : 0, row.currency)}
+
+
+ {row => row.count}
+
+
+ {row => row.unique_count}
+
+
+ );
+}
+
+export default AttributionTable;
diff --git a/src/app/(main)/reports/attribution/AttributionView.module.css b/src/app/(main)/reports/attribution/AttributionView.module.css
new file mode 100644
index 00000000..f242b1d9
--- /dev/null
+++ b/src/app/(main)/reports/attribution/AttributionView.module.css
@@ -0,0 +1,20 @@
+.container {
+ display: grid;
+ gap: 20px;
+ margin-bottom: 40px;
+}
+
+.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;
+}
diff --git a/src/app/(main)/reports/attribution/AttributionView.tsx b/src/app/(main)/reports/attribution/AttributionView.tsx
new file mode 100644
index 00000000..e5b22451
--- /dev/null
+++ b/src/app/(main)/reports/attribution/AttributionView.tsx
@@ -0,0 +1,134 @@
+import PieChart from '@/components/charts/PieChart';
+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 { CHART_COLORS } from '@/lib/constants';
+import { formatLongNumber } from '@/lib/format';
+import { useContext } from 'react';
+import { ReportContext } from '../[reportId]/Report';
+import styles from './AttributionView.module.css';
+
+export interface AttributionViewProps {
+ isLoading?: boolean;
+}
+
+export function AttributionView({ isLoading }: AttributionViewProps) {
+ const { formatMessage, labels } = useMessages();
+ const { report } = useContext(ReportContext);
+ const {
+ data,
+ parameters: { currency },
+ } = report || {};
+ const ATTRIBUTION_PARAMS = [
+ { value: 'referrer', label: formatMessage(labels.referrers) },
+ { value: 'paidAds', label: formatMessage(labels.paidAds) },
+ ];
+
+ if (!data) {
+ return null;
+ }
+
+ const { pageviews, visitors, visits } = data.total;
+
+ 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,
+ },
+ ]
+ : [];
+
+ 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 (
+ ({
+ x: name,
+ y: Number(value),
+ z: (value / total) * 100,
+ }))}
+ />
+ );
+ }
+
+ return (
+
+
+ {metrics?.map(({ label, value, formatValue }) => {
+ return ;
+ })}
+
+ {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 (
+
+
+
{label}
+
({
+ x: name,
+ y: Number(value),
+ z: (value / total) * 100,
+ }))}
+ />
+
+
+
+ );
+ })}
+
+
+
+
+
+
+
+
+
+
+
+
+ );
+}
+
+export default AttributionView;
diff --git a/src/app/(main)/reports/attribution/page.tsx b/src/app/(main)/reports/attribution/page.tsx
new file mode 100644
index 00000000..9efd6220
--- /dev/null
+++ b/src/app/(main)/reports/attribution/page.tsx
@@ -0,0 +1,10 @@
+import AttributionReportPage from './AttributionReportPage';
+import { Metadata } from 'next';
+
+export default function () {
+ return ;
+}
+
+export const metadata: Metadata = {
+ title: 'Attribution Report',
+};
diff --git a/src/app/(main)/reports/create/ReportTemplates.tsx b/src/app/(main)/reports/create/ReportTemplates.tsx
index c26e3a91..4748b5c9 100644
--- a/src/app/(main)/reports/create/ReportTemplates.tsx
+++ b/src/app/(main)/reports/create/ReportTemplates.tsx
@@ -58,6 +58,12 @@ export function ReportTemplates({ showHeader = true }: { showHeader?: boolean })
url: renderTeamUrl('/reports/revenue'),
icon: ,
},
+ {
+ title: formatMessage(labels.attribution),
+ description: formatMessage(labels.attributionDescription),
+ url: renderTeamUrl('/reports/attribution'),
+ icon: ,
+ },
];
return (
diff --git a/src/app/api/reports/attribution/route.ts b/src/app/api/reports/attribution/route.ts
new file mode 100644
index 00000000..a1f7992d
--- /dev/null
+++ b/src/app/api/reports/attribution/route.ts
@@ -0,0 +1,50 @@
+import { canViewWebsite } from '@/lib/auth';
+import { parseRequest } from '@/lib/request';
+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,
+ model: z.string().regex(/firstClick|lastClick/i),
+ steps: z
+ .array(
+ z.object({
+ type: z.string(),
+ value: z.string(),
+ }),
+ )
+ .min(1),
+ currency: z.string().optional(),
+ });
+
+ const { auth, body, error } = await parseRequest(request, schema);
+
+ if (error) {
+ return error();
+ }
+
+ const {
+ websiteId,
+ model,
+ steps,
+ currency,
+ dateRange: { startDate, endDate },
+ } = body;
+
+ if (!(await canViewWebsite(auth, websiteId))) {
+ return unauthorized();
+ }
+
+ const data = await getAttribution(websiteId, {
+ startDate: new Date(startDate),
+ endDate: new Date(endDate),
+ model: model,
+ steps,
+ currency,
+ });
+
+ return json(data);
+}
diff --git a/src/components/messages.ts b/src/components/messages.ts
index 5279e1b4..8c4f5a32 100644
--- a/src/components/messages.ts
+++ b/src/components/messages.ts
@@ -163,7 +163,13 @@ export const labels = defineMessages({
id: 'label.revenue-description',
defaultMessage: 'Look into your revenue data and how users are spending.',
},
+ attribution: { id: 'label.attribution', defaultMessage: 'Attribution' },
+ attributionDescription: {
+ id: 'label.attribution-description',
+ defaultMessage: 'See how users engage with your marketing and what drives conversions.',
+ },
currency: { id: 'label.currency', defaultMessage: 'Currency' },
+ model: { id: 'label.model', defaultMessage: 'Model' },
url: { id: 'label.url', defaultMessage: 'URL' },
urls: { id: 'label.urls', defaultMessage: 'URLs' },
path: { id: 'label.path', defaultMessage: 'Path' },
@@ -257,6 +263,7 @@ export const labels = defineMessages({
id: 'label.utm-description',
defaultMessage: 'Track your campaigns through UTM parameters.',
},
+ conversionStep: { id: 'label.conversion-step', defaultMessage: 'Conversion Step' },
steps: { id: 'label.steps', defaultMessage: 'Steps' },
startStep: { id: 'label.start-step', defaultMessage: 'Start Step' },
endStep: { id: 'label.end-step', defaultMessage: 'End Step' },
@@ -281,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' },
diff --git a/src/components/metrics/ListTable.tsx b/src/components/metrics/ListTable.tsx
index 6fbf390a..f5dbbee5 100644
--- a/src/components/metrics/ListTable.tsx
+++ b/src/components/metrics/ListTable.tsx
@@ -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
{change}
- {props.y?.to(formatLongNumber)}
+ {currency
+ ? props.y?.to(n => formatLongCurrency(n, currency))
+ : props.y?.to(formatLongNumber)}
{showPercentage && (
diff --git a/src/lib/constants.ts b/src/lib/constants.ts
index 3eddefdc..07b979aa 100644
--- a/src/lib/constants.ts
+++ b/src/lib/constants.ts
@@ -124,6 +124,7 @@ export const REPORT_TYPES = {
utm: 'utm',
journey: 'journey',
revenue: 'revenue',
+ attribution: 'attribution',
} as const;
export const REPORT_PARAMETERS = {
diff --git a/src/lib/schema.ts b/src/lib/schema.ts
index 4e2b3e4a..1997a54c 100644
--- a/src/lib/schema.ts
+++ b/src/lib/schema.ts
@@ -60,6 +60,7 @@ export const reportTypeParam = z.enum([
'goals',
'journey',
'revenue',
+ 'attribution',
]);
export const reportParms = {
diff --git a/src/queries/sql/reports/getAttribution.ts b/src/queries/sql/reports/getAttribution.ts
new file mode 100644
index 00000000..62003222
--- /dev/null
+++ b/src/queries/sql/reports/getAttribution.ts
@@ -0,0 +1,475 @@
+import clickhouse from '@/lib/clickhouse';
+import { EVENT_TYPE } from '@/lib/constants';
+import { CLICKHOUSE, PRISMA, runQuery } from '@/lib/db';
+import prisma from '@/lib/prisma';
+
+export async function getAttribution(
+ ...args: [
+ websiteId: string,
+ criteria: {
+ startDate: Date;
+ endDate: Date;
+ model: string;
+ steps: { type: string; value: string }[];
+ currency: string;
+ },
+ ]
+) {
+ return runQuery({
+ [PRISMA]: () => relationalQuery(...args),
+ [CLICKHOUSE]: () => clickhouseQuery(...args),
+ });
+}
+
+async function relationalQuery(
+ websiteId: string,
+ criteria: {
+ startDate: Date;
+ endDate: Date;
+ model: string;
+ steps: { type: string; value: string }[];
+ currency: string;
+ },
+): 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 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`;
+ }
+
+ 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(
+ `
+ ${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(
+ `
+ ${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: {
+ startDate: Date;
+ endDate: Date;
+ model: string;
+ steps: { type: string; value: string }[];
+ currency: string;
+ },
+): 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 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 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`;
+ }
+
+ 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<
+ {
+ 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,
+ };
+}
diff --git a/src/queries/sql/reports/getRevenue.ts b/src/queries/sql/reports/getRevenue.ts
index c9c7b74a..f1fb1d73 100644
--- a/src/queries/sql/reports/getRevenue.ts
+++ b/src/queries/sql/reports/getRevenue.ts
@@ -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}