-- 删除现有的物化视图(需要先删除视图,因为它们依赖于表) 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.qr_scans; DROP TABLE IF EXISTS limq.sessions; DROP TABLE IF EXISTS limq.link_events; DROP TABLE IF EXISTS limq.links; -- 创建数据库(如果不存在) CREATE DATABASE IF NOT EXISTS limq; -- 切换到limq数据库 USE limq; -- 创建短链接访问事件表 CREATE TABLE IF NOT EXISTS limq.link_events ( event_id UUID DEFAULT generateUUIDv4(), event_time DateTime64(3) DEFAULT now64(), date Date DEFAULT toDate(event_time), link_id String, channel_id String, visitor_id String, session_id String, event_type Enum8( 'click' = 1, 'redirect' = 2, 'conversion' = 3, 'error' = 4 ), -- 访问者信息 ip_address String, country String, city String, -- 来源信息 referrer String, utm_source String, utm_medium String, utm_campaign String, -- 设备信息 user_agent String, device_type Enum8( 'mobile' = 1, 'tablet' = 2, 'desktop' = 3, 'other' = 4 ), browser String, os String, -- 交互信息 time_spent_sec UInt32 DEFAULT 0, is_bounce Boolean DEFAULT true, -- QR码相关 is_qr_scan Boolean DEFAULT false, qr_code_id String DEFAULT '', -- 转化数据 conversion_type Enum8( 'visit' = 1, 'stay' = 2, 'interact' = 3, 'signup' = 4, 'subscription' = 5, 'purchase' = 6 ) DEFAULT 'visit', conversion_value Float64 DEFAULT 0, -- 其他属性 custom_data String DEFAULT '{}' ) ENGINE = MergeTree() PARTITION BY toYYYYMM(date) ORDER BY (date, link_id, event_time) SETTINGS index_granularity = 8192; -- 短链接维度表 CREATE TABLE IF NOT EXISTS limq.links ( link_id String, original_url String, created_at DateTime64(3), created_by String, title String, description String, tags Array(String), is_active Boolean DEFAULT true, expires_at Nullable(DateTime64(3)), team_id String DEFAULT '', project_id String DEFAULT '', PRIMARY KEY (link_id) ) ENGINE = ReplacingMergeTree() ORDER BY link_id SETTINGS index_granularity = 8192; -- 会话跟踪表 CREATE TABLE IF NOT EXISTS limq.sessions ( session_id String, visitor_id String, link_id String, started_at DateTime64(3), last_activity DateTime64(3), ended_at Nullable(DateTime64(3)), duration_sec UInt32 DEFAULT 0, session_pages UInt8 DEFAULT 1, is_completed Boolean DEFAULT false, PRIMARY KEY (session_id) ) ENGINE = ReplacingMergeTree(last_activity) ORDER BY (session_id, link_id, visitor_id) SETTINGS index_granularity = 8192; -- QR码统计表 CREATE TABLE IF NOT EXISTS limq.qr_scans ( scan_id UUID DEFAULT generateUUIDv4(), qr_code_id String, link_id String, scan_time DateTime64(3), visitor_id String, location String, device_type Enum8( 'mobile' = 1, 'tablet' = 2, 'desktop' = 3, 'other' = 4 ), led_to_conversion Boolean DEFAULT false, PRIMARY KEY (scan_id) ) ENGINE = MergeTree() PARTITION BY toYYYYMM(scan_time) ORDER BY scan_id SETTINGS index_granularity = 8192; -- 每日链接汇总视图 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;