umami/db/clickhouse/schema.sql

177 lines
4.5 KiB
MySQL
Raw Normal View History

2022-09-12 18:55:34 +02:00
-- Create Event
2023-03-29 20:06:12 +02:00
CREATE TABLE umami.website_event
(
2022-10-09 01:12:33 +02:00
website_id UUID,
session_id UUID,
2024-03-21 17:30:42 +01:00
visit_id UUID,
2023-03-23 07:02:37 +01:00
event_id UUID,
--sessions
hostname LowCardinality(String),
browser LowCardinality(String),
os LowCardinality(String),
device LowCardinality(String),
screen LowCardinality(String),
language LowCardinality(String),
2022-09-12 18:55:34 +02:00
country LowCardinality(String),
subdivision1 LowCardinality(String),
2023-02-16 18:52:07 +01:00
subdivision2 LowCardinality(String),
2023-02-15 18:40:49 +01:00
city String,
--pageviews
2023-03-15 01:27:17 +01:00
url_path String,
url_query String,
referrer_path String,
referrer_query String,
referrer_domain String,
2023-02-15 18:40:49 +01:00
page_title String,
--events
event_type UInt32,
2022-09-12 18:55:34 +02:00
event_name String,
2023-06-26 17:19:52 +02:00
created_at DateTime('UTC'),
job_id Nullable(UUID)
)
2022-09-12 18:55:34 +02:00
engine = MergeTree
2022-10-12 06:02:15 +02:00
ORDER BY (website_id, session_id, created_at)
SETTINGS index_granularity = 8192;
2023-03-23 07:02:37 +01:00
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,
2023-06-26 17:19:52 +02:00
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)
2023-03-23 07:02:37 +01:00
)
engine = MergeTree
ORDER BY (website_id, session_id, data_key, created_at)
2024-07-23 06:30:06 +02:00
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),
2024-07-23 06:30:06 +02:00
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')),
created_at Datetime('UTC')
)
ENGINE = AggregatingMergeTree
PARTITION BY toYYYYMM(created_at)
ORDER BY (
website_id,
toStartOfHour(created_at),
cityHash64(visit_id),
2024-07-24 00:34:25 +02:00
visit_id,
event_type
2024-07-23 06:30:06 +02:00
)
SAMPLE BY cityHash64(visit_id);
2024-07-23 06:30:06 +02:00
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,
2024-07-23 06:30:06 +02:00
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,
timestamp as created_at
FROM (SELECT
website_id,
session_id,
visit_id,
hostname,
browser,
os,
device,
screen,
language,
2024-07-23 06:30:06 +02:00
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,
toStartOfHour(created_at) timestamp
FROM umami.website_event
GROUP BY website_id,
session_id,
visit_id,
hostname,
browser,
os,
device,
screen,
language,
2024-07-23 06:30:06 +02:00
country,
subdivision1,
city,
event_type,
2024-07-24 00:34:25 +02:00
timestamp);