mirror of
https://github.com/umami-software/umami.git
synced 2026-02-10 15:47:13 +01:00
implement filtering and cohorts to all relevant queries
This commit is contained in:
parent
789b8b36d8
commit
2f1f704728
34 changed files with 311 additions and 167 deletions
|
|
@ -38,18 +38,33 @@ async function relationalQuery(
|
|||
): Promise<RevenueResult> {
|
||||
const { startDate, endDate, currency, unit = 'day' } = parameters;
|
||||
const { getDateSQL, rawQuery, parseFilters } = prisma;
|
||||
const { queryParams } = parseFilters({ ...filters, websiteId, startDate, endDate, currency });
|
||||
const { queryParams, filterQuery, cohortQuery, joinSessionQuery } = parseFilters({
|
||||
...filters,
|
||||
websiteId,
|
||||
startDate,
|
||||
endDate,
|
||||
currency,
|
||||
});
|
||||
|
||||
const chart = await rawQuery(
|
||||
`
|
||||
select
|
||||
event_name x,
|
||||
${getDateSQL('created_at', unit)} t,
|
||||
sum(revenue) y
|
||||
revenue.event_name x,
|
||||
${getDateSQL('revenue.created_at', unit)} t,
|
||||
sum(revenue.revenue) y
|
||||
from revenue
|
||||
where website_id = {{websiteId::uuid}}
|
||||
and created_at between {{startDate}} and {{endDate}}
|
||||
and currency like {{currency}}
|
||||
join website_event
|
||||
on website_event.website_id = revenue.website_id
|
||||
and website_event.session_id = revenue.session_id
|
||||
and website_event.event_id = revenue.event_id
|
||||
and website_event.website_id = {{websiteId::uuid}}
|
||||
and website_event.created_at between {{startDate}} and {{endDate}}
|
||||
${cohortQuery}
|
||||
${joinSessionQuery}
|
||||
where revenue.website_id = {{websiteId::uuid}}
|
||||
and revenue.created_at between {{startDate}} and {{endDate}}
|
||||
and revenue.currency like {{currency}}
|
||||
${filterQuery}
|
||||
group by x, t
|
||||
order by t
|
||||
`,
|
||||
|
|
@ -59,15 +74,24 @@ async function relationalQuery(
|
|||
const country = await rawQuery(
|
||||
`
|
||||
select
|
||||
s.country as name,
|
||||
session.country as name,
|
||||
sum(r.revenue) value
|
||||
from revenue r
|
||||
join session s
|
||||
on s.session_id = r.session_id
|
||||
where r.website_id = {{websiteId::uuid}}
|
||||
and r.created_at between {{startDate}} and {{endDate}}
|
||||
and r.currency = {{currency}}
|
||||
group by s.country
|
||||
from revenue
|
||||
join website_event
|
||||
on website_event.website_id = revenue.website_id
|
||||
and website_event.session_id = revenue.session_id
|
||||
and website_event.event_id = revenue.event_id
|
||||
and website_event.website_id = {{websiteId::uuid}}
|
||||
and website_event.created_at between {{startDate}} and {{endDate}}
|
||||
join session
|
||||
on session.website_id = revenue.website_id
|
||||
and session.session_id = revenue.session_id
|
||||
${cohortQuery}
|
||||
where revenue.website_id = {{websiteId::uuid}}
|
||||
and revenue.created_at between {{startDate}} and {{endDate}}
|
||||
and revenue.currency = {{currency}}
|
||||
${filterQuery}
|
||||
group by session.country
|
||||
`,
|
||||
queryParams,
|
||||
);
|
||||
|
|
@ -75,13 +99,22 @@ async function relationalQuery(
|
|||
const total = await rawQuery(
|
||||
`
|
||||
select
|
||||
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}}
|
||||
and currency = {{currency}}
|
||||
sum(revenue.revenue) as sum,
|
||||
count(distinct revenue.event_id) as count,
|
||||
count(distinct revenue.session_id) as unique_count
|
||||
from revenue
|
||||
join website_event
|
||||
on website_event.website_id = revenue.website_id
|
||||
and website_event.session_id = revenue.session_id
|
||||
and website_event.event_id = revenue.event_id
|
||||
and website_event.website_id = {{websiteId::uuid}}
|
||||
and website_event.created_at between {{startDate}} and {{endDate}}
|
||||
${cohortQuery}
|
||||
${joinSessionQuery}
|
||||
where revenue.website_id = {{websiteId::uuid}}
|
||||
and revenue.created_at between {{startDate}} and {{endDate}}
|
||||
and revenue.currency = {{currency}}
|
||||
${filterQuery}
|
||||
`,
|
||||
queryParams,
|
||||
).then(result => result?.[0]);
|
||||
|
|
@ -91,14 +124,23 @@ async function relationalQuery(
|
|||
const table = await rawQuery(
|
||||
`
|
||||
select
|
||||
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
|
||||
revenue.currency,
|
||||
sum(revenue.revenue) as sum,
|
||||
count(distinct revenue.event_id) as count,
|
||||
count(distinct revenue.session_id) as unique_count
|
||||
from revenue
|
||||
join website_event
|
||||
on website_event.website_id = revenue.website_id
|
||||
and website_event.session_id = revenue.session_id
|
||||
and website_event.event_id = revenue.event_id
|
||||
and website_event.website_id = {{websiteId::uuid}}
|
||||
and website_event.created_at between {{startDate}} and {{endDate}}
|
||||
${cohortQuery}
|
||||
${joinSessionQuery}
|
||||
where revenue.website_id = {{websiteId::uuid}}
|
||||
and revenue.created_at between {{startDate}} and {{endDate}}
|
||||
${filterQuery}
|
||||
group by revenue.currency
|
||||
order by sum desc
|
||||
`,
|
||||
queryParams,
|
||||
|
|
@ -114,7 +156,7 @@ async function clickhouseQuery(
|
|||
): Promise<RevenueResult> {
|
||||
const { startDate, endDate, unit = 'day', currency } = parameters;
|
||||
const { getDateSQL, rawQuery, parseFilters } = clickhouse;
|
||||
const { queryParams } = parseFilters({
|
||||
const { filterQuery, cohortQuery, queryParams } = parseFilters({
|
||||
...filters,
|
||||
websiteId,
|
||||
startDate,
|
||||
|
|
@ -131,13 +173,21 @@ async function clickhouseQuery(
|
|||
>(
|
||||
`
|
||||
select
|
||||
event_name x,
|
||||
${getDateSQL('created_at', unit)} t,
|
||||
sum(revenue) y
|
||||
website_revenue.event_name x,
|
||||
${getDateSQL('website_revenue.created_at', unit)} t,
|
||||
sum(website_revenue.revenue) y
|
||||
from website_revenue
|
||||
where website_id = {websiteId:UUID}
|
||||
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
and currency = {currency:String}
|
||||
join website_event
|
||||
on website_event.website_id = website_revenue.website_id
|
||||
and website_event.session_id = website_revenue.session_id
|
||||
and website_event.event_id = website_revenue.event_id
|
||||
and website_event.website_id = {websiteId:UUID}
|
||||
and website_event.created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
${cohortQuery}
|
||||
where website_revenue.website_id = {websiteId:UUID}
|
||||
and website_revenue.created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
and website_revenue.currency = {currency:String}
|
||||
${filterQuery}
|
||||
group by x, t
|
||||
order by t
|
||||
`,
|
||||
|
|
@ -152,20 +202,21 @@ async function clickhouseQuery(
|
|||
>(
|
||||
`
|
||||
select
|
||||
s.country as name,
|
||||
sum(w.revenue) as value
|
||||
from website_revenue w
|
||||
join (
|
||||
select distinct website_id, session_id, country
|
||||
from website_event
|
||||
where website_id = {websiteId:UUID}
|
||||
) s
|
||||
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
|
||||
website_event.country as name,
|
||||
sum(website_revenue.revenue) as value
|
||||
from website_revenue
|
||||
join website_event
|
||||
on website_event.website_id = website_revenue.website_id
|
||||
and website_event.session_id = website_revenue.session_id
|
||||
and website_event.event_id = website_revenue.event_id
|
||||
and website_event.website_id = {websiteId:UUID}
|
||||
and website_event.created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
${cohortQuery}
|
||||
where website_revenue.website_id = {websiteId:UUID}
|
||||
and website_revenue.created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
and website_revenue.currency = {currency:String}
|
||||
${filterQuery}
|
||||
group by website_event.country
|
||||
`,
|
||||
queryParams,
|
||||
);
|
||||
|
|
@ -177,13 +228,21 @@ async function clickhouseQuery(
|
|||
}>(
|
||||
`
|
||||
select
|
||||
sum(revenue) as sum,
|
||||
uniqExact(event_id) as count,
|
||||
uniqExact(session_id) as unique_count
|
||||
sum(website_revenue.revenue) as sum,
|
||||
uniqExact(website_revenue.event_id) as count,
|
||||
uniqExact(website_revenue.session_id) as unique_count
|
||||
from website_revenue
|
||||
where website_id = {websiteId:UUID}
|
||||
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
and currency = {currency:String}
|
||||
join website_event
|
||||
on website_event.website_id = website_revenue.website_id
|
||||
and website_event.session_id = website_revenue.session_id
|
||||
and website_event.event_id = website_revenue.event_id
|
||||
and website_event.website_id = {websiteId:UUID}
|
||||
and website_event.created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
${cohortQuery}
|
||||
where website_revenue.website_id = {websiteId:UUID}
|
||||
and website_revenue.created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
and website_revenue.currency = {currency:String}
|
||||
${filterQuery}
|
||||
`,
|
||||
queryParams,
|
||||
).then(result => result?.[0]);
|
||||
|
|
@ -200,14 +259,22 @@ async function clickhouseQuery(
|
|||
>(
|
||||
`
|
||||
select
|
||||
currency,
|
||||
sum(revenue) as sum,
|
||||
uniqExact(event_id) as count,
|
||||
uniqExact(session_id) as unique_count
|
||||
website_revenue.currency,
|
||||
sum(website_revenue.revenue) as sum,
|
||||
uniqExact(website_revenue.event_id) as count,
|
||||
uniqExact(website_revenue.session_id) as unique_count
|
||||
from website_revenue
|
||||
where website_id = {websiteId:UUID}
|
||||
and created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
group by currency
|
||||
join website_event
|
||||
on website_event.website_id = website_revenue.website_id
|
||||
and website_event.session_id = website_revenue.session_id
|
||||
and website_event.event_id = website_revenue.event_id
|
||||
and website_event.website_id = {websiteId:UUID}
|
||||
and website_event.created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
${cohortQuery}
|
||||
where website_revenue.website_id = {websiteId:UUID}
|
||||
and website_revenue.created_at between {startDate:DateTime64} and {endDate:DateTime64}
|
||||
${filterQuery}
|
||||
group by website_revenue.currency
|
||||
order by sum desc
|
||||
`,
|
||||
queryParams,
|
||||
|
|
|
|||
Loading…
Add table
Add a link
Reference in a new issue