chang sql

This commit is contained in:
2025-03-21 15:42:24 +08:00
parent e0f9018a20
commit 4a04fc322c
3 changed files with 189 additions and 173 deletions

View File

@@ -1,11 +1,17 @@
-- 删除现有的物化视图(需要先删除视图,因为它们依赖于表)
-- 删除所有物化视图(需要先删除视图,因为它们依赖于表)
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;
DROP TABLE IF EXISTS limq.qrcode_daily_stats;
-- 删除所有表
DROP TABLE IF EXISTS limq.qr_scans;
DROP TABLE IF EXISTS limq.sessions;
@@ -14,6 +20,16 @@ DROP TABLE IF EXISTS limq.link_events;
DROP TABLE IF EXISTS limq.links;
DROP TABLE IF EXISTS limq.teams;
DROP TABLE IF EXISTS limq.projects;
DROP TABLE IF EXISTS limq.qrcodes;
DROP TABLE IF EXISTS limq.team_members;
DROP TABLE IF EXISTS limq.users;
-- 创建数据库(如果不存在)
CREATE DATABASE IF NOT EXISTS limq;
@@ -130,6 +146,114 @@ CREATE TABLE IF NOT EXISTS limq.qr_scans (
ORDER BY
scan_id SETTINGS index_granularity = 8192;
-- 团队表
CREATE TABLE IF NOT EXISTS limq.teams (
team_id String,
name String,
created_at DateTime,
created_by String,
description String DEFAULT '',
avatar_url String DEFAULT '',
is_active Boolean DEFAULT true,
plan_type Enum8(
'free' = 1,
'pro' = 2,
'enterprise' = 3
),
members_count UInt32 DEFAULT 1,
PRIMARY KEY (team_id)
) ENGINE = ReplacingMergeTree()
ORDER BY
team_id SETTINGS index_granularity = 8192;
-- 项目表
CREATE TABLE IF NOT EXISTS limq.projects (
project_id String,
team_id String,
name String,
created_at DateTime,
created_by String,
description String DEFAULT '',
is_archived Boolean DEFAULT false,
links_count UInt32 DEFAULT 0,
total_clicks UInt64 DEFAULT 0,
last_updated DateTime DEFAULT now(),
PRIMARY KEY (project_id)
) ENGINE = ReplacingMergeTree()
ORDER BY
(project_id, team_id) SETTINGS index_granularity = 8192;
-- QR码表
CREATE TABLE IF NOT EXISTS limq.qrcodes (
qr_code_id String,
link_id String,
team_id String,
project_id String DEFAULT '',
name String,
description String DEFAULT '',
created_at DateTime,
created_by String,
updated_at DateTime DEFAULT now(),
qr_type Enum8(
'standard' = 1,
'custom' = 2,
'dynamic' = 3
) DEFAULT 'standard',
image_url String DEFAULT '',
design_config String DEFAULT '{}',
is_active Boolean DEFAULT true,
total_scans UInt64 DEFAULT 0,
unique_scanners UInt32 DEFAULT 0,
PRIMARY KEY (qr_code_id)
) ENGINE = ReplacingMergeTree()
ORDER BY
(qr_code_id, link_id) SETTINGS index_granularity = 8192;
-- 团队成员表
CREATE TABLE IF NOT EXISTS limq.team_members (
team_id String,
user_id String,
role Enum8(
'owner' = 1,
'admin' = 2,
'editor' = 3,
'viewer' = 4
),
joined_at DateTime DEFAULT now(),
invited_by String,
is_active Boolean DEFAULT true,
last_active DateTime DEFAULT now(),
PRIMARY KEY (team_id, user_id)
) ENGINE = ReplacingMergeTree()
ORDER BY
(team_id, user_id) SETTINGS index_granularity = 8192;
-- 用户表
CREATE TABLE IF NOT EXISTS limq.users (
user_id String,
username String,
email String,
full_name String,
avatar_url String DEFAULT '',
created_at DateTime,
last_login DateTime DEFAULT now(),
is_active Boolean DEFAULT true,
is_verified Boolean DEFAULT false,
auth_provider Enum8(
'email' = 1,
'google' = 2,
'github' = 3,
'microsoft' = 4
) DEFAULT 'email',
roles Array(String) DEFAULT [ 'user' ],
preferences String DEFAULT '{}',
teams_count UInt32 DEFAULT 0,
links_created UInt32 DEFAULT 0,
PRIMARY KEY (user_id)
) ENGINE = ReplacingMergeTree()
ORDER BY
user_id SETTINGS index_granularity = 8192;
-- 每日链接汇总视图
CREATE MATERIALIZED VIEW IF NOT EXISTS limq.link_daily_stats ENGINE = SummingMergeTree() PARTITION BY toYYYYMM(date)
ORDER BY
@@ -190,4 +314,66 @@ WHERE
GROUP BY
date,
utm_source,
device_type;
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;
-- QR码每日统计视图
CREATE MATERIALIZED VIEW IF NOT EXISTS limq.qrcode_daily_stats ENGINE = SummingMergeTree() PARTITION BY toYYYYMM(date)
ORDER BY
(date, qr_code_id) SETTINGS index_granularity = 8192 AS
SELECT
toDate(scan_time) AS date,
qr_code_id,
count() AS total_scans,
uniqExact(visitor_id) AS unique_scanners,
countIf(led_to_conversion) AS conversions,
countIf(device_type = 'mobile') AS mobile_scans,
countIf(device_type = 'tablet') AS tablet_scans,
countIf(device_type = 'desktop') AS desktop_scans,
uniqExact(location) AS unique_locations
FROM
limq.qr_scans
GROUP BY
date,
qr_code_id;