diff --git a/src/queries/sql/reports/getAttribution.ts b/src/queries/sql/reports/getAttribution.ts index f224eb5c..b3a8a704 100644 --- a/src/queries/sql/reports/getAttribution.ts +++ b/src/queries/sql/reports/getAttribution.ts @@ -78,26 +78,16 @@ async function relationalQuery( group by 1),`; const revenueEventQuery = `WITH events AS ( - select - we.session_id, - max(ed.created_at) max_dt, - sum(coalesce(cast(number_value as decimal(10,2)), cast(string_value as decimal(10,2)))) value - from event_data ed - join website_event we - on we.event_id = ed.website_event_id - and we.website_id = ed.website_id - join (select website_event_id - from event_data - 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}} - and ed.created_at between {{startDate}} and {{endDate}} - and ${column} = {{conversionStep}} - and ed.data_key ${like} '%revenue%' - group by 1),`; + select + session_id, + max(created_at) max_dt, + sum(revenue) value + from revenue + where website_id = {{websiteId::uuid}} + and created_at between {{startDate}} and {{endDate}} + and ${column} = {{conversionStep}} + and currency ${like} {{currency}} + group by 1),`; function getModelQuery(model: string) { return model === 'firstClick' diff --git a/src/queries/sql/reports/getRevenue.ts b/src/queries/sql/reports/getRevenue.ts index f7996fcc..8f4855cc 100644 --- a/src/queries/sql/reports/getRevenue.ts +++ b/src/queries/sql/reports/getRevenue.ts @@ -48,22 +48,13 @@ async function relationalQuery( const chartRes = await rawQuery( ` select - we.event_name x, - ${getDateSQL('ed.created_at', unit, timezone)} t, - sum(coalesce(cast(number_value as decimal(10,2)), cast(string_value as decimal(10,2)))) y - from event_data ed - join website_event we - on we.event_id = ed.website_event_id - join (select website_event_id - from event_data - 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}} - and ed.created_at between {{startDate}} and {{endDate}} - and ed.data_key ${like} '%revenue%' + event_name x, + ${getDateSQL('created_at', unit, timezone)} t, + sum(revenue) y + from revenue + where website_id = {{websiteId::uuid}} + and created_at between {{startDate}} and {{endDate}} + and currency ${like} {{currency}} group by x, t order by t `, @@ -74,22 +65,13 @@ async function relationalQuery( ` select s.country as name, - sum(coalesce(cast(number_value as decimal(10,2)), cast(string_value as decimal(10,2)))) value - from event_data ed - join website_event we - on we.event_id = ed.website_event_id + sum(r.revenue) value + from revenue r join session s - on s.session_id = we.session_id - join (select website_event_id - from event_data - 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}} - and ed.created_at between {{startDate}} and {{endDate}} - and ed.data_key ${like} '%revenue%' + on s.session_id = r.session_id + where r.website_id = {{websiteId::uuid}} + and r.created_at between {{startDate}} and {{endDate}} + and r.currency ${like} {{currency}} group by s.country `, { websiteId, startDate, endDate, currency }, @@ -98,22 +80,13 @@ async function relationalQuery( const totalRes = await rawQuery( ` select - sum(coalesce(cast(number_value as decimal(10,2)), cast(string_value as decimal(10,2)))) as sum, + sum(revenue) as sum, count(distinct event_id) as count, count(distinct session_id) as unique_count - from event_data ed - join website_event we - on we.event_id = ed.website_event_id - join (select website_event_id - from event_data - 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}} - and ed.created_at between {{startDate}} and {{endDate}} - and ed.data_key ${like} '%revenue%' + from revenue r + where website_id = {{websiteId::uuid}} + and created_at between {{startDate}} and {{endDate}} + and currency ${like} {{currency}} `, { websiteId, startDate, endDate, currency }, ).then(result => result?.[0]); @@ -121,24 +94,15 @@ async function relationalQuery( const tableRes = await rawQuery( ` select - c.currency, - sum(coalesce(cast(number_value as decimal(10,2)), cast(string_value as decimal(10,2)))) as sum, - count(distinct ed.website_event_id) as count, - count(distinct we.session_id) as unique_count - from event_data ed - join website_event we - on we.event_id = ed.website_event_id - join (select website_event_id, string_value as currency - from event_data - where 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}} - and ed.data_key ${like} '%revenue%' - group by c.currency - order by sum desc; + currency, + sum(revenue) as sum, + count(distinct event_id) as count, + count(distinct session_id) as unique_count + from revenue r + where website_id = {{websiteId::uuid}} + and created_at between {{startDate}} and {{endDate}} + group by currency + order by sum desc `, { websiteId, startDate, endDate, unit, timezone, currency }, );