mirror of
https://github.com/umami-software/umami.git
synced 2026-02-04 12:47:13 +01:00
add website_revenue table and view. update revenue report to use view
This commit is contained in:
parent
57acaf9855
commit
a16846f4ce
2 changed files with 55 additions and 48 deletions
|
|
@ -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 },
|
||||
);
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue