sync event data
This commit is contained in:
122
scripts/db/sql/clickhouse/modify_device_type.sql
Normal file
122
scripts/db/sql/clickhouse/modify_device_type.sql
Normal file
@@ -0,0 +1,122 @@
|
||||
-- 修改设备类型字段从枚举类型更改为字符串类型
|
||||
-- 先删除依赖于link_events表的物化视图
|
||||
DROP TABLE IF EXISTS limq.platform_distribution;
|
||||
|
||||
DROP TABLE IF EXISTS limq.link_hourly_patterns;
|
||||
|
||||
DROP TABLE IF EXISTS limq.link_daily_stats;
|
||||
|
||||
DROP TABLE IF EXISTS limq.team_daily_stats;
|
||||
|
||||
DROP TABLE IF EXISTS limq.project_daily_stats;
|
||||
|
||||
-- 修改link_events表的device_type字段
|
||||
ALTER TABLE
|
||||
limq.link_events
|
||||
MODIFY
|
||||
COLUMN device_type String;
|
||||
|
||||
-- 重新创建物化视图
|
||||
-- 每日链接汇总视图
|
||||
CREATE MATERIALIZED VIEW IF NOT EXISTS limq.link_daily_stats ENGINE = SummingMergeTree() PARTITION BY toYYYYMM(date)
|
||||
ORDER BY
|
||||
(date, link_id) SETTINGS index_granularity = 8192 AS
|
||||
SELECT
|
||||
toDate(event_time) AS date,
|
||||
link_id,
|
||||
count() AS total_clicks,
|
||||
uniqExact(visitor_id) AS unique_visitors,
|
||||
uniqExact(session_id) AS unique_sessions,
|
||||
sum(time_spent_sec) AS total_time_spent,
|
||||
avg(time_spent_sec) AS avg_time_spent,
|
||||
countIf(is_bounce) AS bounce_count,
|
||||
countIf(event_type = 'conversion') AS conversion_count,
|
||||
uniqExact(referrer) AS unique_referrers,
|
||||
countIf(device_type = 'mobile') AS mobile_count,
|
||||
countIf(device_type = 'tablet') AS tablet_count,
|
||||
countIf(device_type = 'desktop') AS desktop_count,
|
||||
countIf(is_qr_scan) AS qr_scan_count,
|
||||
sum(conversion_value) AS total_conversion_value
|
||||
FROM
|
||||
limq.link_events
|
||||
GROUP BY
|
||||
date,
|
||||
link_id;
|
||||
|
||||
-- 每小时访问模式视图
|
||||
CREATE MATERIALIZED VIEW IF NOT EXISTS limq.link_hourly_patterns ENGINE = SummingMergeTree() PARTITION BY toYYYYMM(date)
|
||||
ORDER BY
|
||||
(date, hour, link_id) SETTINGS index_granularity = 8192 AS
|
||||
SELECT
|
||||
toDate(event_time) AS date,
|
||||
toHour(event_time) AS hour,
|
||||
link_id,
|
||||
count() AS visits,
|
||||
uniqExact(visitor_id) AS unique_visitors
|
||||
FROM
|
||||
limq.link_events
|
||||
GROUP BY
|
||||
date,
|
||||
hour,
|
||||
link_id;
|
||||
|
||||
-- 平台分布视图
|
||||
CREATE MATERIALIZED VIEW IF NOT EXISTS limq.platform_distribution ENGINE = SummingMergeTree() PARTITION BY toYYYYMM(date)
|
||||
ORDER BY
|
||||
(date, utm_source, device_type) SETTINGS index_granularity = 8192 AS
|
||||
SELECT
|
||||
toDate(event_time) AS date,
|
||||
utm_source,
|
||||
device_type,
|
||||
count() AS visits,
|
||||
uniqExact(visitor_id) AS unique_visitors
|
||||
FROM
|
||||
limq.link_events
|
||||
WHERE
|
||||
utm_source != ''
|
||||
GROUP BY
|
||||
date,
|
||||
utm_source,
|
||||
device_type;
|
||||
|
||||
-- 团队每日统计视图
|
||||
CREATE MATERIALIZED VIEW IF NOT EXISTS limq.team_daily_stats ENGINE = SummingMergeTree() PARTITION BY toYYYYMM(date)
|
||||
ORDER BY
|
||||
(date, team_id) SETTINGS index_granularity = 8192 AS
|
||||
SELECT
|
||||
toDate(event_time) AS date,
|
||||
l.team_id AS team_id,
|
||||
count() AS total_clicks,
|
||||
uniqExact(e.visitor_id) AS unique_visitors,
|
||||
countIf(e.event_type = 'conversion') AS conversion_count,
|
||||
uniqExact(e.link_id) AS links_used,
|
||||
countIf(e.is_qr_scan) AS qr_scan_count
|
||||
FROM
|
||||
limq.link_events e
|
||||
JOIN limq.links l ON e.link_id = l.link_id
|
||||
WHERE
|
||||
l.team_id != ''
|
||||
GROUP BY
|
||||
date,
|
||||
l.team_id;
|
||||
|
||||
-- 项目每日统计视图
|
||||
CREATE MATERIALIZED VIEW IF NOT EXISTS limq.project_daily_stats ENGINE = SummingMergeTree() PARTITION BY toYYYYMM(date)
|
||||
ORDER BY
|
||||
(date, project_id) SETTINGS index_granularity = 8192 AS
|
||||
SELECT
|
||||
toDate(event_time) AS date,
|
||||
l.project_id AS project_id,
|
||||
count() AS total_clicks,
|
||||
uniqExact(e.visitor_id) AS unique_visitors,
|
||||
countIf(e.event_type = 'conversion') AS conversion_count,
|
||||
uniqExact(e.link_id) AS links_used,
|
||||
countIf(e.is_qr_scan) AS qr_scan_count
|
||||
FROM
|
||||
limq.link_events e
|
||||
JOIN limq.links l ON e.link_id = l.link_id
|
||||
WHERE
|
||||
l.project_id != ''
|
||||
GROUP BY
|
||||
date,
|
||||
l.project_id;
|
||||
Reference in New Issue
Block a user