Files
vf_react/database_migration.sql
2025-11-19 19:41:26 +08:00

428 lines
13 KiB
SQL

-- ============================================
-- 订阅支付系统数据库迁移 SQL
-- 版本: v2.0.0
-- 日期: 2025-11-19
-- ============================================
-- ============================================
-- 第一步: 备份现有数据
-- ============================================
-- 创建备份表
CREATE TABLE IF NOT EXISTS user_subscriptions_backup AS SELECT * FROM user_subscriptions;
CREATE TABLE IF NOT EXISTS payment_orders_backup AS SELECT * FROM payment_orders;
CREATE TABLE IF NOT EXISTS subscription_plans_backup AS SELECT * FROM subscription_plans;
-- ============================================
-- 第二步: 删除旧表(先删除外键依赖的表)
-- ============================================
DROP TABLE IF EXISTS subscription_upgrades; -- 删除升级表,不再使用
DROP TABLE IF EXISTS promo_code_usage; -- 暂时删除,稍后重建
DROP TABLE IF EXISTS payment_orders; -- 删除旧订单表
DROP TABLE IF EXISTS user_subscriptions; -- 删除旧订阅表
DROP TABLE IF EXISTS subscription_plans; -- 删除旧套餐表
-- ============================================
-- 第三步: 创建新表结构
-- ============================================
-- 1. 订阅套餐表(重构)
CREATE TABLE subscription_plans (
id INT PRIMARY KEY AUTO_INCREMENT,
plan_code VARCHAR(20) NOT NULL UNIQUE COMMENT '套餐代码: pro, max',
plan_name VARCHAR(50) NOT NULL COMMENT '套餐名称: Pro专业版, Max旗舰版',
description TEXT COMMENT '套餐描述',
features JSON COMMENT '功能列表',
-- 价格配置(所有周期价格)
price_monthly DECIMAL(10,2) NOT NULL DEFAULT 0 COMMENT '月付价格',
price_quarterly DECIMAL(10,2) NOT NULL DEFAULT 0 COMMENT '季付价格(3个月)',
price_semiannual DECIMAL(10,2) NOT NULL DEFAULT 0 COMMENT '半年付价格(6个月)',
price_yearly DECIMAL(10,2) NOT NULL DEFAULT 0 COMMENT '年付价格(12个月)',
-- 状态字段
is_active BOOLEAN DEFAULT TRUE COMMENT '是否启用',
display_order INT DEFAULT 0 COMMENT '展示顺序',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
INDEX idx_plan_code (plan_code),
INDEX idx_active_order (is_active, display_order)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='订阅套餐配置表';
-- 2. 用户订阅记录表(重构)
CREATE TABLE user_subscriptions (
id INT PRIMARY KEY AUTO_INCREMENT,
user_id INT NOT NULL COMMENT '用户ID',
subscription_id VARCHAR(32) UNIQUE NOT NULL COMMENT '订阅ID(唯一标识)',
-- 订阅基本信息
plan_code VARCHAR(20) NOT NULL COMMENT '套餐代码: pro, max, free',
billing_cycle VARCHAR(20) NOT NULL COMMENT '计费周期: monthly, quarterly, semiannual, yearly',
-- 订阅时间
start_date DATETIME NOT NULL COMMENT '订阅开始时间',
end_date DATETIME NOT NULL COMMENT '订阅结束时间',
-- 订阅状态
status VARCHAR(20) NOT NULL DEFAULT 'active' COMMENT '状态: active(有效), expired(已过期), cancelled(已取消)',
is_current BOOLEAN DEFAULT FALSE COMMENT '是否为当前生效的订阅',
-- 支付信息
payment_order_id INT COMMENT '关联的支付订单ID',
paid_amount DECIMAL(10,2) NOT NULL DEFAULT 0 COMMENT '实际支付金额',
original_price DECIMAL(10,2) NOT NULL DEFAULT 0 COMMENT '原价',
discount_amount DECIMAL(10,2) DEFAULT 0 COMMENT '优惠金额',
-- 订阅类型
subscription_type VARCHAR(20) DEFAULT 'new' COMMENT '订阅类型: new(新购), renew(续费)',
previous_subscription_id VARCHAR(32) COMMENT '上一个订阅ID(续费时记录)',
-- 自动续费
auto_renew BOOLEAN DEFAULT FALSE COMMENT '是否自动续费',
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
updated_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP,
INDEX idx_user_id (user_id),
INDEX idx_subscription_id (subscription_id),
INDEX idx_user_current (user_id, is_current),
INDEX idx_status (status),
INDEX idx_end_date (end_date)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='用户订阅记录表';
-- 3. 支付订单表(重构)
CREATE TABLE payment_orders (
id INT PRIMARY KEY AUTO_INCREMENT,
order_no VARCHAR(32) UNIQUE NOT NULL COMMENT '订单号',
user_id INT NOT NULL COMMENT '用户ID',
-- 订阅信息
plan_code VARCHAR(20) NOT NULL COMMENT '套餐代码',
billing_cycle VARCHAR(20) NOT NULL COMMENT '计费周期',
subscription_type VARCHAR(20) DEFAULT 'new' COMMENT '订阅类型: new(新购), renew(续费)',
-- 价格信息
original_price DECIMAL(10,2) NOT NULL COMMENT '原价',
discount_amount DECIMAL(10,2) DEFAULT 0 COMMENT '优惠金额',
final_amount DECIMAL(10,2) NOT NULL COMMENT '实付金额',
-- 优惠码
promo_code_id INT COMMENT '优惠码ID',
promo_code VARCHAR(50) COMMENT '优惠码',
-- 支付信息
payment_method VARCHAR(20) DEFAULT 'wechat' COMMENT '支付方式: wechat, alipay',
payment_channel VARCHAR(50) COMMENT '支付渠道详情',
transaction_id VARCHAR(64) COMMENT '第三方交易号',
qr_code_url TEXT COMMENT '支付二维码URL',
-- 订单状态
status VARCHAR(20) DEFAULT 'pending' COMMENT '状态: pending(待支付), paid(已支付), expired(已过期), cancelled(已取消)',
-- 时间信息
created_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
paid_at TIMESTAMP NULL COMMENT '支付时间',
expired_at TIMESTAMP NULL COMMENT '过期时间',
-- 备注
remark TEXT COMMENT '备注信息',
INDEX idx_order_no (order_no),
INDEX idx_user_id (user_id),
INDEX idx_status (status),
INDEX idx_created_at (created_at)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='支付订单表';
-- 4. 优惠码使用记录表(重建)
CREATE TABLE promo_code_usage (
id INT PRIMARY KEY AUTO_INCREMENT,
promo_code_id INT NOT NULL,
user_id INT NOT NULL,
order_id INT NOT NULL,
discount_amount DECIMAL(10,2) NOT NULL COMMENT '实际优惠金额',
used_at TIMESTAMP DEFAULT CURRENT_TIMESTAMP,
INDEX idx_promo_code (promo_code_id),
INDEX idx_user_id (user_id),
INDEX idx_order_id (order_id)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COMMENT='优惠码使用记录表';
-- ============================================
-- 第四步: 插入初始数据
-- ============================================
-- 插入套餐数据
INSERT INTO subscription_plans (
plan_code,
plan_name,
description,
price_monthly,
price_quarterly,
price_semiannual,
price_yearly,
features,
display_order,
is_active
) VALUES
(
'pro',
'Pro 专业版',
'为专业投资者打造,解锁高级分析功能',
299.00,
799.00,
1499.00,
2699.00,
JSON_ARRAY(
'新闻信息流',
'历史事件对比',
'事件传导链分析(AI)',
'事件-相关标的分析',
'相关概念展示',
'AI复盘功能',
'企业概览',
'个股深度分析(AI) - 50家/月',
'高效数据筛选工具',
'概念中心(548大概念)',
'历史时间轴查询 - 100天',
'涨停板块数据分析',
'个股涨停分析'
),
1,
TRUE
),
(
'max',
'Max 旗舰版',
'旗舰级体验,无限制使用所有功能',
599.00,
1599.00,
2999.00,
5399.00,
JSON_ARRAY(
'全部 Pro 版功能',
'板块深度分析(AI)',
'个股深度分析(AI) - 无限制',
'历史时间轴查询 - 无限制',
'概念高频更新',
'优先客服支持',
'独家功能抢先体验'
),
2,
TRUE
);
-- ============================================
-- 第五步: 数据迁移(可选)
-- ============================================
-- 如果需要迁移旧数据,取消以下注释:
/*
-- 迁移旧的用户订阅数据
INSERT INTO user_subscriptions (
user_id,
subscription_id,
plan_code,
billing_cycle,
start_date,
end_date,
status,
is_current,
paid_amount,
original_price,
subscription_type,
auto_renew,
created_at
)
SELECT
user_id,
CONCAT('SUB_', id, '_', UNIX_TIMESTAMP(NOW())), -- 生成订阅ID
subscription_type, -- 将 subscription_type 映射为 plan_code
COALESCE(billing_cycle, 'yearly'), -- 默认年付
COALESCE(start_date, NOW()),
COALESCE(end_date, DATE_ADD(NOW(), INTERVAL 365 DAY)),
subscription_status,
TRUE, -- 设为当前订阅
0, -- 旧数据没有支付金额,设为0
0, -- 旧数据没有原价,设为0
'new', -- 默认为新购
COALESCE(auto_renewal, FALSE),
created_at
FROM user_subscriptions_backup
WHERE subscription_type IN ('pro', 'max'); -- 只迁移付费用户
*/
-- ============================================
-- 第六步: 创建免费订阅记录(为所有用户)
-- ============================================
-- 为所有现有用户创建免费订阅记录(如果没有付费订阅)
/*
INSERT INTO user_subscriptions (
user_id,
subscription_id,
plan_code,
billing_cycle,
start_date,
end_date,
status,
is_current,
paid_amount,
original_price,
subscription_type
)
SELECT
id AS user_id,
CONCAT('FREE_', id, '_', UNIX_TIMESTAMP(NOW())),
'free',
'monthly',
NOW(),
'2099-12-31 23:59:59', -- 免费版永久有效
'active',
TRUE,
0,
0,
'new'
FROM user
WHERE id NOT IN (
SELECT DISTINCT user_id FROM user_subscriptions WHERE plan_code IN ('pro', 'max')
);
*/
-- ============================================
-- 第七步: 验证数据完整性
-- ============================================
-- 检查套餐数据
SELECT * FROM subscription_plans;
-- 检查用户订阅数据
SELECT
plan_code,
COUNT(*) as user_count,
SUM(CASE WHEN is_current = TRUE THEN 1 ELSE 0 END) as current_count
FROM user_subscriptions
GROUP BY plan_code;
-- 检查支付订单数据
SELECT
status,
COUNT(*) as order_count,
SUM(final_amount) as total_amount
FROM payment_orders
GROUP BY status;
-- ============================================
-- 第八步: 添加外键约束(可选)
-- ============================================
-- 注意: 只有在确认 users 表存在且数据完整时才执行
-- ALTER TABLE user_subscriptions
-- ADD CONSTRAINT fk_user_subscriptions_user
-- FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE;
-- ALTER TABLE payment_orders
-- ADD CONSTRAINT fk_payment_orders_user
-- FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE;
-- ALTER TABLE payment_orders
-- ADD CONSTRAINT fk_payment_orders_promo
-- FOREIGN KEY (promo_code_id) REFERENCES promo_codes(id) ON DELETE SET NULL;
-- ALTER TABLE promo_code_usage
-- ADD CONSTRAINT fk_promo_usage_promo
-- FOREIGN KEY (promo_code_id) REFERENCES promo_codes(id) ON DELETE CASCADE;
-- ALTER TABLE promo_code_usage
-- ADD CONSTRAINT fk_promo_usage_user
-- FOREIGN KEY (user_id) REFERENCES users(id) ON DELETE CASCADE;
-- ALTER TABLE promo_code_usage
-- ADD CONSTRAINT fk_promo_usage_order
-- FOREIGN KEY (order_id) REFERENCES payment_orders(id) ON DELETE CASCADE;
-- ============================================
-- 第九步: 创建测试数据(开发环境)
-- ============================================
-- 插入测试优惠码
INSERT INTO promo_codes (
code,
description,
discount_type,
discount_value,
applicable_plans,
applicable_cycles,
max_total_uses,
max_uses_per_user,
valid_from,
valid_until,
is_active
) VALUES
(
'WELCOME2025',
'2025新用户专享',
'percentage',
20.00,
NULL, -- 适用所有套餐
NULL, -- 适用所有周期
1000,
1,
NOW(),
DATE_ADD(NOW(), INTERVAL 90 DAY),
TRUE
),
(
'YEAR2025',
'年付专享',
'percentage',
10.00,
NULL,
JSON_ARRAY('yearly'), -- 仅适用年付
500,
1,
NOW(),
DATE_ADD(NOW(), INTERVAL 365 DAY),
TRUE
),
(
'TESTCODE',
'测试优惠码 - 固定减100元',
'fixed_amount',
100.00,
NULL,
NULL,
100,
1,
NOW(),
DATE_ADD(NOW(), INTERVAL 30 DAY),
TRUE
);
-- ============================================
-- 迁移完成提示
-- ============================================
SELECT '===================================' AS '';
SELECT '数据库迁移完成!' AS '状态';
SELECT '===================================' AS '';
SELECT '请检查以下数据:' AS '提示';
SELECT '1. subscription_plans 表是否有2条记录 (pro, max)' AS '';
SELECT '2. user_subscriptions 表数据是否正确' AS '';
SELECT '3. payment_orders 表结构是否正确' AS '';
SELECT '4. 备份表 (*_backup) 已创建' AS '';
SELECT '===================================' AS '';
SELECT '下一步: 更新后端代码 (app.py, models.py)' AS '';
SELECT '===================================' AS '';