mirror of
https://github.com/kremalicious/umami.git
synced 2025-02-06 01:15:42 +01:00
199 lines
5.3 KiB
SQL
199 lines
5.3 KiB
SQL
-- Create Event
|
|
CREATE TABLE umami.website_event
|
|
(
|
|
website_id UUID,
|
|
session_id UUID,
|
|
visit_id UUID,
|
|
event_id UUID,
|
|
--sessions
|
|
hostname LowCardinality(String),
|
|
browser LowCardinality(String),
|
|
os LowCardinality(String),
|
|
device LowCardinality(String),
|
|
screen LowCardinality(String),
|
|
language LowCardinality(String),
|
|
country LowCardinality(String),
|
|
subdivision1 LowCardinality(String),
|
|
subdivision2 LowCardinality(String),
|
|
city String,
|
|
--pageviews
|
|
url_path String,
|
|
url_query String,
|
|
referrer_path String,
|
|
referrer_query String,
|
|
referrer_domain String,
|
|
page_title String,
|
|
--events
|
|
event_type UInt32,
|
|
event_name String,
|
|
tag String,
|
|
created_at DateTime('UTC'),
|
|
job_id Nullable(UUID)
|
|
)
|
|
ENGINE = MergeTree
|
|
PARTITION BY toYYYYMM(created_at)
|
|
ORDER BY (toStartOfHour(created_at), website_id, session_id, visit_id, created_at)
|
|
PRIMARY KEY (toStartOfHour(created_at), website_id, session_id, visit_id)
|
|
SETTINGS index_granularity = 8192;
|
|
|
|
CREATE TABLE umami.event_data
|
|
(
|
|
website_id UUID,
|
|
session_id UUID,
|
|
event_id UUID,
|
|
url_path String,
|
|
event_name String,
|
|
data_key String,
|
|
string_value Nullable(String),
|
|
number_value Nullable(Decimal64(4)),
|
|
date_value Nullable(DateTime('UTC')),
|
|
data_type UInt32,
|
|
created_at DateTime('UTC'),
|
|
job_id Nullable(UUID)
|
|
)
|
|
ENGINE = MergeTree
|
|
ORDER BY (website_id, event_id, data_key, created_at)
|
|
SETTINGS index_granularity = 8192;
|
|
|
|
CREATE TABLE umami.session_data
|
|
(
|
|
website_id UUID,
|
|
session_id UUID,
|
|
data_key String,
|
|
string_value Nullable(String),
|
|
number_value Nullable(Decimal64(4)),
|
|
date_value Nullable(DateTime('UTC')),
|
|
data_type UInt32,
|
|
created_at DateTime('UTC'),
|
|
job_id Nullable(UUID)
|
|
)
|
|
ENGINE = ReplacingMergeTree
|
|
ORDER BY (website_id, session_id, data_key)
|
|
SETTINGS index_granularity = 8192;
|
|
|
|
-- stats hourly
|
|
CREATE TABLE umami.website_event_stats_hourly
|
|
(
|
|
website_id UUID,
|
|
session_id UUID,
|
|
visit_id UUID,
|
|
hostname LowCardinality(String),
|
|
browser LowCardinality(String),
|
|
os LowCardinality(String),
|
|
device LowCardinality(String),
|
|
screen LowCardinality(String),
|
|
language LowCardinality(String),
|
|
country LowCardinality(String),
|
|
subdivision1 LowCardinality(String),
|
|
city String,
|
|
entry_url AggregateFunction(argMin, String, DateTime('UTC')),
|
|
exit_url AggregateFunction(argMax, String, DateTime('UTC')),
|
|
url_path SimpleAggregateFunction(groupArrayArray, Array(String)),
|
|
url_query SimpleAggregateFunction(groupArrayArray, Array(String)),
|
|
referrer_domain SimpleAggregateFunction(groupArrayArray, Array(String)),
|
|
page_title SimpleAggregateFunction(groupArrayArray, Array(String)),
|
|
event_type UInt32,
|
|
event_name SimpleAggregateFunction(groupArrayArray, Array(String)),
|
|
views SimpleAggregateFunction(sum, UInt64),
|
|
min_time SimpleAggregateFunction(min, DateTime('UTC')),
|
|
max_time SimpleAggregateFunction(max, DateTime('UTC')),
|
|
tag SimpleAggregateFunction(groupArrayArray, Array(String)),
|
|
created_at Datetime('UTC')
|
|
)
|
|
ENGINE = AggregatingMergeTree
|
|
PARTITION BY toYYYYMM(created_at)
|
|
ORDER BY (
|
|
website_id,
|
|
event_type,
|
|
toStartOfHour(created_at),
|
|
cityHash64(visit_id),
|
|
visit_id
|
|
)
|
|
SAMPLE BY cityHash64(visit_id);
|
|
|
|
CREATE MATERIALIZED VIEW umami.website_event_stats_hourly_mv
|
|
TO umami.website_event_stats_hourly
|
|
AS
|
|
SELECT
|
|
website_id,
|
|
session_id,
|
|
visit_id,
|
|
hostname,
|
|
browser,
|
|
os,
|
|
device,
|
|
screen,
|
|
language,
|
|
country,
|
|
subdivision1,
|
|
city,
|
|
entry_url,
|
|
exit_url,
|
|
url_paths as url_path,
|
|
url_query,
|
|
referrer_domain,
|
|
page_title,
|
|
event_type,
|
|
event_name,
|
|
views,
|
|
min_time,
|
|
max_time,
|
|
tag,
|
|
timestamp as created_at
|
|
FROM (SELECT
|
|
website_id,
|
|
session_id,
|
|
visit_id,
|
|
hostname,
|
|
browser,
|
|
os,
|
|
device,
|
|
screen,
|
|
language,
|
|
country,
|
|
subdivision1,
|
|
city,
|
|
argMinState(url_path, created_at) entry_url,
|
|
argMaxState(url_path, created_at) exit_url,
|
|
arrayFilter(x -> x != '', groupArray(url_path)) as url_paths,
|
|
arrayFilter(x -> x != '', groupArray(url_query)) url_query,
|
|
arrayFilter(x -> x != '', groupArray(referrer_domain)) referrer_domain,
|
|
arrayFilter(x -> x != '', groupArray(page_title)) page_title,
|
|
event_type,
|
|
if(event_type = 2, groupArray(event_name), []) event_name,
|
|
sumIf(1, event_type = 1) views,
|
|
min(created_at) min_time,
|
|
max(created_at) max_time,
|
|
arrayFilter(x -> x != '', groupArray(tag)) tag,
|
|
toStartOfHour(created_at) timestamp
|
|
FROM umami.website_event
|
|
GROUP BY website_id,
|
|
session_id,
|
|
visit_id,
|
|
hostname,
|
|
browser,
|
|
os,
|
|
device,
|
|
screen,
|
|
language,
|
|
country,
|
|
subdivision1,
|
|
city,
|
|
event_type,
|
|
timestamp);
|
|
|
|
-- projections
|
|
ALTER TABLE umami.website_event
|
|
ADD PROJECTION website_event_url_path_projection (
|
|
SELECT * ORDER BY toStartOfDay(created_at), website_id, url_path, created_at
|
|
);
|
|
|
|
ALTER TABLE umami.website_event MATERIALIZE PROJECTION website_event_url_path_projection;
|
|
|
|
ALTER TABLE umami.website_event
|
|
ADD PROJECTION website_event_referrer_domain_projection (
|
|
SELECT * ORDER BY toStartOfDay(created_at), website_id, referrer_domain, created_at
|
|
);
|
|
|
|
ALTER TABLE umami.website_event MATERIALIZE PROJECTION website_event_referrer_domain_projection;
|