From a16846f4ce2cbed81eeb3be7a1c02222fddc90be Mon Sep 17 00:00:00 2001 From: Francis Cao Date: Fri, 6 Jun 2025 08:47:52 -0700 Subject: [PATCH] add website_revenue table and view. update revenue report to use view --- db/clickhouse/schema.sql | 35 ++++++++++++++ src/queries/sql/reports/getRevenue.ts | 68 ++++++++------------------- 2 files changed, 55 insertions(+), 48 deletions(-) diff --git a/db/clickhouse/schema.sql b/db/clickhouse/schema.sql index fef600e0..ff85112b 100644 --- a/db/clickhouse/schema.sql +++ b/db/clickhouse/schema.sql @@ -246,3 +246,38 @@ SELECT * ORDER BY toStartOfDay(created_at), website_id, referrer_domain, created ); ALTER TABLE umami.website_event MATERIALIZE PROJECTION website_event_referrer_domain_projection; + +-- revenue +CREATE TABLE umami.website_revenue +( + website_id UUID, + session_id UUID, + event_id UUID, + event_name String, + currency String, + revenue DECIMAL(18,4), + created_at DateTime('UTC') +) +ENGINE = MergeTree + PARTITION BY toYYYYMM(created_at) + ORDER BY (website_id, session_id, created_at) + SETTINGS index_granularity = 8192; + + +CREATE MATERIALIZED VIEW umami.website_revenue_mv +TO umami.website_revenue +AS +SELECT DISTINCT + ed.website_id, + ed.session_id, + ed.event_id, + ed.event_name, + c.currency, + coalesce(toDecimal64(ed.number_value, 2), toDecimal64(ed.string_value, 2)) revenue, + ed.created_at +FROM umami.event_data ed +JOIN (SELECT event_id, string_value as currency + FROM event_data + WHERE positionCaseInsensitive(data_key, 'currency') > 0) c + ON c.event_id = ed.event_id +WHERE positionCaseInsensitive(data_key, 'revenue') > 0; diff --git a/src/queries/sql/reports/getRevenue.ts b/src/queries/sql/reports/getRevenue.ts index f1fb1d73..f7996fcc 100644 --- a/src/queries/sql/reports/getRevenue.ts +++ b/src/queries/sql/reports/getRevenue.ts @@ -180,18 +180,11 @@ async function clickhouseQuery( select event_name x, ${getDateSQL('created_at', unit, timezone)} t, - sum(coalesce(toDecimal64(number_value, 2), toDecimal64(string_value, 2))) y - from event_data - join (select event_id - from event_data - where 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 + sum(revenue) y + from website_revenue where website_id = {websiteId:UUID} and created_at between {startDate:DateTime64} and {endDate:DateTime64} - and positionCaseInsensitive(data_key, 'revenue') > 0 + and currency = {currency:String} group by x, t order by t `, @@ -207,23 +200,16 @@ async function clickhouseQuery( ` select s.country as name, - sum(coalesce(toDecimal64(number_value, 2), toDecimal64(string_value, 2))) as value - from event_data ed - join (select event_id - from event_data - where 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 + sum(w.revenue) as value + from website_revenue w join (select distinct website_id, session_id, country from website_event_stats_hourly where website_id = {websiteId:UUID}) s - on ed.website_id = s.website_id - and ed.session_id = s.session_id - where ed.website_id = {websiteId:UUID} - and ed.created_at between {startDate:DateTime64} and {endDate:DateTime64} - and positionCaseInsensitive(ed.data_key, 'revenue') > 0 + on w.website_id = s.website_id + and w.session_id = s.session_id + where w.website_id = {websiteId:UUID} + and w.created_at between {startDate:DateTime64} and {endDate:DateTime64} + and w.currency = {currency:String} group by s.country `, { websiteId, startDate, endDate, currency }, @@ -237,20 +223,13 @@ async function clickhouseQuery( }>( ` select - sum(coalesce(toDecimal64(number_value, 2), toDecimal64(string_value, 2))) as sum, + sum(revenue) as sum, uniqExact(event_id) as count, uniqExact(session_id) as unique_count - from event_data - 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}) currency - on currency.event_id = event_data.event_id + from website_revenue where website_id = {websiteId:UUID} and created_at between {startDate:DateTime64} and {endDate:DateTime64} - and positionCaseInsensitive(data_key, 'revenue') > 0 + and currency = {currency:String} `, { websiteId, startDate, endDate, currency }, ).then(result => result?.[0]); @@ -266,22 +245,15 @@ async function clickhouseQuery( >( ` select - c.currency, - sum(coalesce(toDecimal64(ed.number_value, 2), toDecimal64(ed.string_value, 2))) as sum, - uniqExact(ed.event_id) as count, - uniqExact(ed.session_id) as unique_count - from event_data ed - join (select event_id, string_value as currency - from event_data - 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 + currency, + sum(revenue) as sum, + uniqExact(event_id) as count, + uniqExact(session_id) as unique_count + from website_revenue where website_id = {websiteId:UUID} and created_at between {startDate:DateTime64} and {endDate:DateTime64} - and positionCaseInsensitive(data_key, 'revenue') > 0 - group by c.currency - order by sum desc; + group by currency + order by sum desc `, { websiteId, startDate, endDate, unit, timezone, currency }, );