Skip to content

Commit

Permalink
added revenue per hour
Browse files Browse the repository at this point in the history
  • Loading branch information
StevenStip committed Aug 10, 2018
1 parent 4f7f235 commit c9c6ec5
Show file tree
Hide file tree
Showing 2 changed files with 39 additions and 0 deletions.
Original file line number Diff line number Diff line change
@@ -0,0 +1,27 @@
-- Get the KPI's in 24 hour intervals since install rather than UTC days
with data as (
select e.userID
, first_value(eventTimestamp) over (partition by userID order by eventTimestamp) as "firstEventTimestamp"
-- Calculate the Day Number based on number of 24 hour blocks since timestamp on first event, (i.e. Not UTC day boundaries)
, round(datediff(hh,first_value(eventTimestamp) over (partition by userID order by eventTimestamp),eventTimestamp) / 24 +1 ,2.0):: integer as DayNumber
, e.eventTimestamp
, e.eventName
, e.platform
, convertedProductAmount
, revenueValidated
from events e
where e.eventName in ('newPlayer', 'gameStarted', 'transaction')
and gaUserStartDate > CURRENT_DATE -31
)
select DayNumber
, count(distinct(case when platform like 'IOS%' then userID end )) as "iOS Users"
, count(distinct(case when platform like 'IOS%' and eventName = 'transaction' and revenueValidated in (0,1) and convertedProductAmount > 0 then userID end )) as "iOS Spenders"
, count(case when platform like 'IOS%' and eventName = 'transaction' and revenueValidated in (0,1) and convertedProductAmount > 0 then convertedProductAmount end ) as "iOS Purchases"
, sum(case when platform like 'IOS%' and eventName = 'transaction' and revenueValidated in (0,1) and convertedProductAmount > 0 then convertedProductAmount end ) as "iOS Revenue"
, count(distinct(case when platform like 'ANDROID%' then userID end )) as "Andorid Users"
, count(distinct(case when platform like 'ANDROID%' and eventName = 'transaction' and revenueValidated in (0,1) and convertedProductAmount > 0 then userID end )) as "Android Spenders"
, count(case when platform like 'ANDROID%' and eventName = 'transaction' and revenueValidated in (0,1) and convertedProductAmount > 0 then convertedProductAmount end ) as "Android Purchases"
, sum(case when platform like 'ANDROID%' and eventName = 'transaction' and revenueValidated in (0,1) and convertedProductAmount > 0 then convertedProductAmount end ) as "Android Revenue"
from data
group by DayNumber
order by DayNumber ;
12 changes: 12 additions & 0 deletions KPIs/revenue_per_hour.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,12 @@
/* Get the timestamp and round it down to the hour,
then get the revenue for this hour, the total number of users as well as the total number of spenders within this window.
*/
select date_trunc('hour', eventTimestamp) as time,
to_char(sum(convertedproductamount)/100, '$999,999,999,999.00') as revenue,
count(distinct userid) active_users,
count(distinct case when convertedproductamount>0 then userId end) as spenders
from events
where revenuevalidated not in (2,3)
and eventName in ('gameStarted', 'transaction')
and eventTimestamp between now() - interval '100 hours' and now()
group by 1 order by 1 desc

0 comments on commit c9c6ec5

Please sign in to comment.