mirror of
https://github.com/TryGhost/Ghost.git
synced 2024-11-29 15:12:58 +03:00
606fcbabe7
- TODO: make these run in CI - Right now you run them by running `yarn tb` and then `./script/branch_and_test.sh` - These are snapshot tests that check we get the desired result Co-authored-by: alejandromav <hi@alejandromav.com>
164 lines
5.8 KiB
Plaintext
164 lines
5.8 KiB
Plaintext
DESCRIPTION >
|
|
Summary with general KPIs per date, including visits, page views, bounce rate and average session duration.
|
|
Accepts `date_from` and `date_to` date filter, all historical data if not passed.
|
|
Daily granularity, except when filtering one single day (hourly)
|
|
|
|
TOKEN "dashboard" READ
|
|
TOKEN "stats page" READ
|
|
|
|
NODE timeseries
|
|
DESCRIPTION >
|
|
Generate a timeseries for the specified time range, so we call fill empty data points.
|
|
Filters "future" data points.
|
|
|
|
SQL >
|
|
%
|
|
{% set _single_day = defined(date_from) and day_diff(date_from, date_to) == 0 %}
|
|
with
|
|
{% if defined(date_from) %}
|
|
toStartOfDay(
|
|
toDate(
|
|
{{
|
|
Date(
|
|
date_from,
|
|
description="Starting day for filtering a date range",
|
|
required=False,
|
|
)
|
|
}}
|
|
)
|
|
) as start,
|
|
{% else %} toStartOfDay(timestampAdd(today(), interval -7 day)) as start,
|
|
{% end %}
|
|
{% if defined(date_to) %}
|
|
toStartOfDay(
|
|
toDate(
|
|
{{
|
|
Date(
|
|
date_to,
|
|
description="Finishing day for filtering a date range",
|
|
required=False,
|
|
)
|
|
}}
|
|
)
|
|
) as end
|
|
{% else %} toStartOfDay(today()) as end
|
|
{% end %}
|
|
{% if _single_day %}
|
|
select
|
|
arrayJoin(
|
|
arrayMap(
|
|
x -> toDateTime(x),
|
|
range(
|
|
toUInt32(toDateTime(start)), toUInt32(timestampAdd(end, interval 1 day)), 3600
|
|
)
|
|
)
|
|
) as date
|
|
{% else %}
|
|
select
|
|
arrayJoin(
|
|
arrayMap(
|
|
x -> toDate(x),
|
|
range(toUInt32(start), toUInt32(timestampAdd(end, interval 1 day)), 24 * 3600)
|
|
)
|
|
) as date
|
|
{% end %}
|
|
|
|
NODE pageviews
|
|
DESCRIPTION >
|
|
Group by sessions and calculate metrics at that level
|
|
|
|
SQL >
|
|
%
|
|
{% if defined(date_from) and day_diff(date_from, date_to) == 0 %}
|
|
select
|
|
site_uuid,
|
|
toStartOfHour(timestamp) as date,
|
|
session_id,
|
|
member_status,
|
|
device,
|
|
browser,
|
|
location,
|
|
source,
|
|
pathname,
|
|
uniq(session_id) as visits,
|
|
count() as pageviews,
|
|
case when min(timestamp) = max(timestamp) then 1 else 0 end as is_bounce,
|
|
max(timestamp) as latest_view_aux,
|
|
min(timestamp) as first_view_aux
|
|
from analytics_hits
|
|
where toDate(timestamp) = {{ Date(date_from) }}
|
|
group by toStartOfHour(timestamp), session_id, site_uuid, member_status, device, browser, location, source, pathname
|
|
{% else %}
|
|
select
|
|
site_uuid,
|
|
date,
|
|
member_status,
|
|
device,
|
|
browser,
|
|
location,
|
|
source,
|
|
pathname,
|
|
session_id,
|
|
uniq(session_id) as visits,
|
|
countMerge(pageviews) as pageviews,
|
|
case when min(first_view) = max(latest_view) then 1 else 0 end as is_bounce,
|
|
max(latest_view) as latest_view_aux,
|
|
min(first_view) as first_view_aux
|
|
from analytics_sessions_mv
|
|
where
|
|
{% if defined(date_from) %} date >= {{ Date(date_from) }}
|
|
{% else %} date >= timestampAdd(today(), interval -7 day)
|
|
{% end %}
|
|
{% if defined(date_to) %} and date <= {{ Date(date_to) }}
|
|
{% else %} and date <= today()
|
|
{% end %}
|
|
group by date, session_id, site_uuid, member_status, device, browser, location, source, pathname
|
|
{% end %}
|
|
|
|
NODE data
|
|
DESCRIPTION >
|
|
General KPIs per date, works for both summary metrics and trends charts.
|
|
|
|
SQL >
|
|
select
|
|
site_uuid,
|
|
date,
|
|
member_status,
|
|
device,
|
|
browser,
|
|
location,
|
|
source,
|
|
pathname,
|
|
uniq(session_id) as visits,
|
|
sum(pageviews) as pageviews,
|
|
sum(case when latest_view_aux = first_view_aux then 1 else 0 end) / visits as bounce_rate,
|
|
avg(latest_view_aux - first_view_aux) as avg_session_sec
|
|
from pageviews
|
|
group by date, site_uuid, member_status, device, browser, location, source, pathname
|
|
|
|
NODE endpoint
|
|
DESCRIPTION >
|
|
Join and generate timeseries with metrics
|
|
|
|
SQL >
|
|
%
|
|
select
|
|
a.date as date,
|
|
sum(b.visits) as visits,
|
|
sum(b.pageviews) as pageviews,
|
|
avg(b.bounce_rate) as bounce_rate,
|
|
sum(b.avg_session_sec) as avg_session_sec
|
|
from timeseries a
|
|
left join data b using date
|
|
where
|
|
site_uuid = {{String(site_uuid, 'mock_site_uuid', description="Tenant ID", required=True)}}
|
|
|
|
{% if defined(member_status) %} and member_status IN {{ Array(member_status, "'undefined', 'free', 'paid'", description="Member status to filter on", required=False) }} {% end %}
|
|
{% if defined(device) %} and device = {{ String(device, description="Device to filter on", required=False) }} {% end %}
|
|
{% if defined(browser) %} and browser = {{ String(browser, description="Browser to filter on", required=False) }} {% end %}
|
|
{% if defined(source) %} and source = {{ String(source, description="Source to filter on", required=False) }} {% end %}
|
|
{% if defined(location) %} and location = {{ String(location, description="Location to filter on", required=False) }} {% end %}
|
|
{% if defined(pathname) %} and pathname = {{ String(pathname, description="Pathname to filter on", required=False) }} {% end %}
|
|
group by date
|
|
order by date WITH FILL STEP 1
|