Files
WechatHookBot/plugins/SignInPlugin/database.sql

67 lines
3.5 KiB
SQL
Raw Blame History

This file contains ambiguous Unicode characters
This file contains Unicode characters that might be confused with other characters. If you think that this is intentional, you can safely ignore this warning. Use the Escape button to reveal them.
-- 签到插件数据库表结构
-- MySQL 5.7+ 兼容
-- 创建数据库(可选)
-- CREATE DATABASE IF NOT EXISTS wechat_bot DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
-- USE wechat_bot;
-- 用户签到表
CREATE TABLE IF NOT EXISTS `user_signin` (
`id` INT AUTO_INCREMENT PRIMARY KEY COMMENT '自增ID',
`wxid` VARCHAR(50) NOT NULL COMMENT '用户微信ID',
`nickname` VARCHAR(100) DEFAULT '' COMMENT '用户昵称',
`city` VARCHAR(50) DEFAULT '' COMMENT '用户城市',
`points` INT DEFAULT 0 COMMENT '用户积分',
`last_signin_date` DATE DEFAULT NULL COMMENT '最后签到日期',
`signin_streak` INT DEFAULT 0 COMMENT '连续签到天数',
`total_signin_days` INT DEFAULT 0 COMMENT '总签到天数',
`created_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
`updated_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
UNIQUE KEY `uk_wxid` (`wxid`),
INDEX `idx_points` (`points` DESC),
INDEX `idx_signin_date` (`last_signin_date`),
INDEX `idx_city` (`city`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='用户签到表';
-- 签到记录表(可选,用于记录详细的签到历史)
CREATE TABLE IF NOT EXISTS `signin_records` (
`id` INT AUTO_INCREMENT PRIMARY KEY COMMENT '自增ID',
`wxid` VARCHAR(50) NOT NULL COMMENT '用户微信ID',
`nickname` VARCHAR(100) DEFAULT '' COMMENT '用户昵称',
`signin_date` DATE NOT NULL COMMENT '签到日期',
`points_earned` INT NOT NULL COMMENT '获得积分',
`signin_streak` INT DEFAULT 1 COMMENT '当时的连续签到天数',
`created_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '签到时间',
UNIQUE KEY `uk_wxid_date` (`wxid`, `signin_date`),
INDEX `idx_signin_date` (`signin_date`),
INDEX `idx_wxid` (`wxid`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='签到记录表';
-- 积分变动记录表(记录所有积分增减)
CREATE TABLE IF NOT EXISTS `points_history` (
`id` INT AUTO_INCREMENT PRIMARY KEY COMMENT '自增ID',
`wxid` VARCHAR(50) NOT NULL COMMENT '用户微信ID',
`nickname` VARCHAR(100) DEFAULT '' COMMENT '用户昵称',
`change_type` VARCHAR(20) NOT NULL COMMENT '变动类型: signin(签到), bonus(奖励), consume(消费), admin(管理员调整), other(其他)',
`points_change` INT NOT NULL COMMENT '积分变动数量(正数增加,负数减少)',
`points_before` INT NOT NULL COMMENT '变动前积分',
`points_after` INT NOT NULL COMMENT '变动后积分',
`description` VARCHAR(200) DEFAULT '' COMMENT '变动说明',
`related_id` VARCHAR(50) DEFAULT '' COMMENT '关联ID如订单号、签到记录ID等',
`created_at` TIMESTAMP DEFAULT CURRENT_TIMESTAMP COMMENT '变动时间',
INDEX `idx_wxid` (`wxid`),
INDEX `idx_change_type` (`change_type`),
INDEX `idx_created_at` (`created_at`)
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='积分变动记录表';
-- 积分统计视图(方便查询用户积分汇总)
CREATE OR REPLACE VIEW `v_points_summary` AS
SELECT
wxid,
nickname,
points as current_points,
total_signin_days,
signin_streak,
(SELECT COALESCE(SUM(points_change), 0) FROM points_history ph WHERE ph.wxid = us.wxid AND points_change > 0) as total_earned,
(SELECT COALESCE(SUM(ABS(points_change)), 0) FROM points_history ph WHERE ph.wxid = us.wxid AND points_change < 0) as total_spent
FROM user_signin us;