mirror of
https://github.com/umami-software/umami.git
synced 2026-02-04 04:37:11 +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
|
|
@ -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;
|
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;
|
||||||
|
|
|
||||||
|
|
@ -180,18 +180,11 @@ async function clickhouseQuery(
|
||||||
select
|
select
|
||||||
event_name x,
|
event_name x,
|
||||||
${getDateSQL('created_at', unit, timezone)} t,
|
${getDateSQL('created_at', unit, timezone)} t,
|
||||||
sum(coalesce(toDecimal64(number_value, 2), toDecimal64(string_value, 2))) y
|
sum(revenue) y
|
||||||
from event_data
|
from website_revenue
|
||||||
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
|
|
||||||
where website_id = {websiteId:UUID}
|
where website_id = {websiteId:UUID}
|
||||||
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||||
and positionCaseInsensitive(data_key, 'revenue') > 0
|
and currency = {currency:String}
|
||||||
group by x, t
|
group by x, t
|
||||||
order by t
|
order by t
|
||||||
`,
|
`,
|
||||||
|
|
@ -207,23 +200,16 @@ async function clickhouseQuery(
|
||||||
`
|
`
|
||||||
select
|
select
|
||||||
s.country as name,
|
s.country as name,
|
||||||
sum(coalesce(toDecimal64(number_value, 2), toDecimal64(string_value, 2))) as value
|
sum(w.revenue) as value
|
||||||
from event_data ed
|
from website_revenue w
|
||||||
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
|
|
||||||
join (select distinct website_id, session_id, country
|
join (select distinct website_id, session_id, country
|
||||||
from website_event_stats_hourly
|
from website_event_stats_hourly
|
||||||
where website_id = {websiteId:UUID}) s
|
where website_id = {websiteId:UUID}) s
|
||||||
on ed.website_id = s.website_id
|
on w.website_id = s.website_id
|
||||||
and ed.session_id = s.session_id
|
and w.session_id = s.session_id
|
||||||
where ed.website_id = {websiteId:UUID}
|
where w.website_id = {websiteId:UUID}
|
||||||
and ed.created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
and w.created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||||
and positionCaseInsensitive(ed.data_key, 'revenue') > 0
|
and w.currency = {currency:String}
|
||||||
group by s.country
|
group by s.country
|
||||||
`,
|
`,
|
||||||
{ websiteId, startDate, endDate, currency },
|
{ websiteId, startDate, endDate, currency },
|
||||||
|
|
@ -237,20 +223,13 @@ async function clickhouseQuery(
|
||||||
}>(
|
}>(
|
||||||
`
|
`
|
||||||
select
|
select
|
||||||
sum(coalesce(toDecimal64(number_value, 2), toDecimal64(string_value, 2))) as sum,
|
sum(revenue) as sum,
|
||||||
uniqExact(event_id) as count,
|
uniqExact(event_id) as count,
|
||||||
uniqExact(session_id) as unique_count
|
uniqExact(session_id) as unique_count
|
||||||
from event_data
|
from website_revenue
|
||||||
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
|
|
||||||
where website_id = {websiteId:UUID}
|
where website_id = {websiteId:UUID}
|
||||||
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||||
and positionCaseInsensitive(data_key, 'revenue') > 0
|
and currency = {currency:String}
|
||||||
`,
|
`,
|
||||||
{ websiteId, startDate, endDate, currency },
|
{ websiteId, startDate, endDate, currency },
|
||||||
).then(result => result?.[0]);
|
).then(result => result?.[0]);
|
||||||
|
|
@ -266,22 +245,15 @@ async function clickhouseQuery(
|
||||||
>(
|
>(
|
||||||
`
|
`
|
||||||
select
|
select
|
||||||
c.currency,
|
currency,
|
||||||
sum(coalesce(toDecimal64(ed.number_value, 2), toDecimal64(ed.string_value, 2))) as sum,
|
sum(revenue) as sum,
|
||||||
uniqExact(ed.event_id) as count,
|
uniqExact(event_id) as count,
|
||||||
uniqExact(ed.session_id) as unique_count
|
uniqExact(session_id) as unique_count
|
||||||
from event_data ed
|
from website_revenue
|
||||||
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
|
|
||||||
where website_id = {websiteId:UUID}
|
where website_id = {websiteId:UUID}
|
||||||
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||||
and positionCaseInsensitive(data_key, 'revenue') > 0
|
group by currency
|
||||||
group by c.currency
|
order by sum desc
|
||||||
order by sum desc;
|
|
||||||
`,
|
`,
|
||||||
{ websiteId, startDate, endDate, unit, timezone, currency },
|
{ websiteId, startDate, endDate, unit, timezone, currency },
|
||||||
);
|
);
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue