From c8b4ee8ca55a64ed0634cc1cbfdab0b3c33f6a08 Mon Sep 17 00:00:00 2001 From: Francis Cao Date: Thu, 31 Jul 2025 09:45:19 -0700 Subject: [PATCH] update psql getChannelMetrics --- src/queries/sql/getChannelMetrics.ts | 42 +++++++++++++++++++++------- 1 file changed, 32 insertions(+), 10 deletions(-) diff --git a/src/queries/sql/getChannelMetrics.ts b/src/queries/sql/getChannelMetrics.ts index 9054b18b..c240cc86 100644 --- a/src/queries/sql/getChannelMetrics.ts +++ b/src/queries/sql/getChannelMetrics.ts @@ -29,17 +29,35 @@ async function relationalQuery(websiteId: string, filters: QueryFilters) { return rawQuery( ` - select - referrer_domain as domain, - url_query as query, - count(distinct session_id) as visitors - from website_event - ${cohortQuery} - where website_id = {{websiteId::uuid}} - ${filterQuery} + WITH channels as ( + select case when ${toPostgresPositionClause('utm_medium', ['cp', 'ppc', 'retargeting', 'paid'])} then 'paid' else 'organic' end prefix, + case + when referrer_domain = '' and url_query = '' then 'direct' + when ${toPostgresPositionClause('url_query', PAID_AD_PARAMS)} then 'paidAds' + when ${toPostgresPositionClause('utm_medium', ['referral', 'app', 'link'])} then 'referral' + when position(utm_medium, 'affiliate') > 0 then 'affiliate' + when position(utm_medium, 'sms') > 0 or position(utm_source, 'sms') > 0 then 'sms' + when ${toPostgresPositionClause('referrer_domain', SEARCH_DOMAINS)} or position(utm_medium, 'organic') > 0 then concat(prefix, 'Search') + when ${toPostgresPositionClause('referrer_domain', SOCIAL_DOMAINS)} then concat(prefix, 'Social') + when ${toPostgresPositionClause('referrer_domain', EMAIL_DOMAINS)} or position(utm_medium, 'mail') > 0 then 'email' + when ${toPostgresPositionClause('referrer_domain', SHOPPING_DOMAINS)} or position(utm_medium, 'shop') > 0 then concat(prefix, 'Shopping') + when ${toPostgresPositionClause('referrer_domain', VIDEO_DOMAINS)} or position(utm_medium, 'video') > 0 then concat(prefix, 'Video') + else '' end AS x, + count(distinct session_id) y + from website_event + ${cohortQuery} + where website_id = {{websiteId::uuid}} + and event_type = {{eventType}} ${dateQuery} - group by 1, 2 - order by visitors desc + ${filterQuery} + group by 1, 2 + order by y desc) + + select x, sum(y) y + from channels + where x != '' + group by x + order by y desc; `, queryParams, ); @@ -106,3 +124,7 @@ async function clickhouseQuery( function toClickHouseStringArray(arr: string[]): string { return arr.map(p => `'${p.replace(/'/g, "\\'")}'`).join(', '); } + +function toPostgresPositionClause(column: string, arr: string[]) { + return arr.map(val => `position(${column}, '${val.replace(/'/g, "''")}') > 0`).join(' OR\n '); +}