mirror of
https://github.com/umami-software/umami.git
synced 2026-02-14 09:35:36 +01:00
update psql revenue and attribution report to use new revenue table
This commit is contained in:
parent
fdaf4b5688
commit
a4465aaa43
2 changed files with 37 additions and 83 deletions
|
|
@ -78,26 +78,16 @@ async function relationalQuery(
|
||||||
group by 1),`;
|
group by 1),`;
|
||||||
|
|
||||||
const revenueEventQuery = `WITH events AS (
|
const revenueEventQuery = `WITH events AS (
|
||||||
select
|
select
|
||||||
we.session_id,
|
session_id,
|
||||||
max(ed.created_at) max_dt,
|
max(created_at) max_dt,
|
||||||
sum(coalesce(cast(number_value as decimal(10,2)), cast(string_value as decimal(10,2)))) value
|
sum(revenue) value
|
||||||
from event_data ed
|
from revenue
|
||||||
join website_event we
|
where website_id = {{websiteId::uuid}}
|
||||||
on we.event_id = ed.website_event_id
|
and created_at between {{startDate}} and {{endDate}}
|
||||||
and we.website_id = ed.website_id
|
and ${column} = {{conversionStep}}
|
||||||
join (select website_event_id
|
and currency ${like} {{currency}}
|
||||||
from event_data
|
group by 1),`;
|
||||||
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),`;
|
|
||||||
|
|
||||||
function getModelQuery(model: string) {
|
function getModelQuery(model: string) {
|
||||||
return model === 'firstClick'
|
return model === 'firstClick'
|
||||||
|
|
|
||||||
|
|
@ -48,22 +48,13 @@ async function relationalQuery(
|
||||||
const chartRes = await rawQuery(
|
const chartRes = await rawQuery(
|
||||||
`
|
`
|
||||||
select
|
select
|
||||||
we.event_name x,
|
event_name x,
|
||||||
${getDateSQL('ed.created_at', unit, timezone)} t,
|
${getDateSQL('created_at', unit, timezone)} t,
|
||||||
sum(coalesce(cast(number_value as decimal(10,2)), cast(string_value as decimal(10,2)))) y
|
sum(revenue) y
|
||||||
from event_data ed
|
from revenue
|
||||||
join website_event we
|
where website_id = {{websiteId::uuid}}
|
||||||
on we.event_id = ed.website_event_id
|
and created_at between {{startDate}} and {{endDate}}
|
||||||
join (select website_event_id
|
and currency ${like} {{currency}}
|
||||||
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%'
|
|
||||||
group by x, t
|
group by x, t
|
||||||
order by t
|
order by t
|
||||||
`,
|
`,
|
||||||
|
|
@ -74,22 +65,13 @@ async function relationalQuery(
|
||||||
`
|
`
|
||||||
select
|
select
|
||||||
s.country as name,
|
s.country as name,
|
||||||
sum(coalesce(cast(number_value as decimal(10,2)), cast(string_value as decimal(10,2)))) value
|
sum(r.revenue) value
|
||||||
from event_data ed
|
from revenue r
|
||||||
join website_event we
|
|
||||||
on we.event_id = ed.website_event_id
|
|
||||||
join session s
|
join session s
|
||||||
on s.session_id = we.session_id
|
on s.session_id = r.session_id
|
||||||
join (select website_event_id
|
where r.website_id = {{websiteId::uuid}}
|
||||||
from event_data
|
and r.created_at between {{startDate}} and {{endDate}}
|
||||||
where website_id = {{websiteId::uuid}}
|
and r.currency ${like} {{currency}}
|
||||||
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%'
|
|
||||||
group by s.country
|
group by s.country
|
||||||
`,
|
`,
|
||||||
{ websiteId, startDate, endDate, currency },
|
{ websiteId, startDate, endDate, currency },
|
||||||
|
|
@ -98,22 +80,13 @@ async function relationalQuery(
|
||||||
const totalRes = await rawQuery(
|
const totalRes = await rawQuery(
|
||||||
`
|
`
|
||||||
select
|
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 event_id) as count,
|
||||||
count(distinct session_id) as unique_count
|
count(distinct session_id) as unique_count
|
||||||
from event_data ed
|
from revenue r
|
||||||
join website_event we
|
where website_id = {{websiteId::uuid}}
|
||||||
on we.event_id = ed.website_event_id
|
and created_at between {{startDate}} and {{endDate}}
|
||||||
join (select website_event_id
|
and currency ${like} {{currency}}
|
||||||
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%'
|
|
||||||
`,
|
`,
|
||||||
{ websiteId, startDate, endDate, currency },
|
{ websiteId, startDate, endDate, currency },
|
||||||
).then(result => result?.[0]);
|
).then(result => result?.[0]);
|
||||||
|
|
@ -121,24 +94,15 @@ async function relationalQuery(
|
||||||
const tableRes = await rawQuery(
|
const tableRes = await rawQuery(
|
||||||
`
|
`
|
||||||
select
|
select
|
||||||
c.currency,
|
currency,
|
||||||
sum(coalesce(cast(number_value as decimal(10,2)), cast(string_value as decimal(10,2)))) as sum,
|
sum(revenue) as sum,
|
||||||
count(distinct ed.website_event_id) as count,
|
count(distinct event_id) as count,
|
||||||
count(distinct we.session_id) as unique_count
|
count(distinct session_id) as unique_count
|
||||||
from event_data ed
|
from revenue r
|
||||||
join website_event we
|
where website_id = {{websiteId::uuid}}
|
||||||
on we.event_id = ed.website_event_id
|
and created_at between {{startDate}} and {{endDate}}
|
||||||
join (select website_event_id, string_value as currency
|
group by currency
|
||||||
from event_data
|
order by sum desc
|
||||||
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;
|
|
||||||
`,
|
`,
|
||||||
{ websiteId, startDate, endDate, unit, timezone, currency },
|
{ websiteId, startDate, endDate, unit, timezone, currency },
|
||||||
);
|
);
|
||||||
|
|
|
||||||
Loading…
Add table
Add a link
Reference in a new issue