332 lines
17 KiB
SQL
332 lines
17 KiB
SQL
-- HoTimeDB 测试表结构
|
||
-- 用于测试和示例的MySQL表结构定义
|
||
-- 请根据实际需要修改表结构和字段类型
|
||
|
||
-- 创建数据库(可选)
|
||
CREATE DATABASE IF NOT EXISTS `hotimedb_test` DEFAULT CHARACTER SET utf8mb4 COLLATE utf8mb4_unicode_ci;
|
||
USE `hotimedb_test`;
|
||
|
||
-- 用户表
|
||
DROP TABLE IF EXISTS `app_user`;
|
||
CREATE TABLE `app_user` (
|
||
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT COMMENT '用户ID',
|
||
`name` varchar(100) NOT NULL DEFAULT '' COMMENT '用户姓名',
|
||
`email` varchar(255) NOT NULL DEFAULT '' COMMENT '邮箱地址',
|
||
`password` varchar(255) NOT NULL DEFAULT '' COMMENT '密码hash',
|
||
`phone` varchar(20) NOT NULL DEFAULT '' COMMENT '手机号',
|
||
`age` int(11) NOT NULL DEFAULT '0' COMMENT '年龄',
|
||
`gender` tinyint(4) NOT NULL DEFAULT '0' COMMENT '性别 0-未知 1-男 2-女',
|
||
`avatar` varchar(500) NOT NULL DEFAULT '' COMMENT '头像URL',
|
||
`level` varchar(20) NOT NULL DEFAULT 'normal' COMMENT '用户等级 normal-普通 vip-会员 svip-超级会员',
|
||
`balance` decimal(10,2) NOT NULL DEFAULT '0.00' COMMENT '账户余额',
|
||
`login_count` int(11) NOT NULL DEFAULT '0' COMMENT '登录次数',
|
||
`status` tinyint(4) NOT NULL DEFAULT '1' COMMENT '状态 1-正常 0-禁用 -1-删除',
|
||
`last_login` datetime DEFAULT NULL COMMENT '最后登录时间',
|
||
`created_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
|
||
`updated_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
|
||
`deleted_at` datetime DEFAULT NULL COMMENT '删除时间',
|
||
PRIMARY KEY (`id`),
|
||
UNIQUE KEY `uk_email` (`email`),
|
||
KEY `idx_status` (`status`),
|
||
KEY `idx_level` (`level`),
|
||
KEY `idx_created_time` (`created_time`),
|
||
KEY `idx_deleted_at` (`deleted_at`)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='用户表';
|
||
|
||
-- 用户资料表
|
||
DROP TABLE IF EXISTS `app_profile`;
|
||
CREATE TABLE `app_profile` (
|
||
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT COMMENT 'ID',
|
||
`user_id` bigint(20) unsigned NOT NULL COMMENT '用户ID',
|
||
`real_name` varchar(50) NOT NULL DEFAULT '' COMMENT '真实姓名',
|
||
`id_card` varchar(20) NOT NULL DEFAULT '' COMMENT '身份证号',
|
||
`address` varchar(500) NOT NULL DEFAULT '' COMMENT '地址',
|
||
`bio` text COMMENT '个人简介',
|
||
`verified` tinyint(4) NOT NULL DEFAULT '0' COMMENT '是否认证 1-是 0-否',
|
||
`preferences` json DEFAULT NULL COMMENT '用户偏好设置JSON',
|
||
`created_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
|
||
`updated_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
|
||
PRIMARY KEY (`id`),
|
||
UNIQUE KEY `uk_user_id` (`user_id`),
|
||
KEY `idx_verified` (`verified`)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='用户资料表';
|
||
|
||
-- 部门表
|
||
DROP TABLE IF EXISTS `app_department`;
|
||
CREATE TABLE `app_department` (
|
||
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT COMMENT '部门ID',
|
||
`name` varchar(100) NOT NULL DEFAULT '' COMMENT '部门名称',
|
||
`parent_id` bigint(20) unsigned NOT NULL DEFAULT '0' COMMENT '上级部门ID',
|
||
`manager_id` bigint(20) unsigned NOT NULL DEFAULT '0' COMMENT '部门经理ID',
|
||
`description` text COMMENT '部门描述',
|
||
`sort` int(11) NOT NULL DEFAULT '0' COMMENT '排序',
|
||
`status` tinyint(4) NOT NULL DEFAULT '1' COMMENT '状态 1-正常 0-禁用',
|
||
`created_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
|
||
`updated_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
|
||
PRIMARY KEY (`id`),
|
||
KEY `idx_parent_id` (`parent_id`),
|
||
KEY `idx_manager_id` (`manager_id`),
|
||
KEY `idx_status` (`status`)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='部门表';
|
||
|
||
-- 商品表
|
||
DROP TABLE IF EXISTS `app_product`;
|
||
CREATE TABLE `app_product` (
|
||
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT COMMENT '商品ID',
|
||
`title` varchar(200) NOT NULL DEFAULT '' COMMENT '商品标题',
|
||
`description` text COMMENT '商品描述',
|
||
`price` decimal(10,2) NOT NULL DEFAULT '0.00' COMMENT '商品价格',
|
||
`stock` int(11) NOT NULL DEFAULT '0' COMMENT '库存数量',
|
||
`category_id` bigint(20) unsigned NOT NULL DEFAULT '0' COMMENT '分类ID',
|
||
`brand` varchar(100) NOT NULL DEFAULT '' COMMENT '品牌',
|
||
`tags` varchar(500) NOT NULL DEFAULT '' COMMENT '标签,逗号分隔',
|
||
`images` json DEFAULT NULL COMMENT '商品图片JSON数组',
|
||
`attributes` json DEFAULT NULL COMMENT '商品属性JSON',
|
||
`sales_count` int(11) NOT NULL DEFAULT '0' COMMENT '销售数量',
|
||
`view_count` int(11) NOT NULL DEFAULT '0' COMMENT '浏览数量',
|
||
`sort` int(11) NOT NULL DEFAULT '0' COMMENT '排序',
|
||
`status` tinyint(4) NOT NULL DEFAULT '1' COMMENT '状态 1-上架 0-下架',
|
||
`created_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
|
||
`updated_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
|
||
PRIMARY KEY (`id`),
|
||
KEY `idx_category_id` (`category_id`),
|
||
KEY `idx_price` (`price`),
|
||
KEY `idx_status` (`status`),
|
||
KEY `idx_created_time` (`created_time`),
|
||
FULLTEXT KEY `ft_title_description` (`title`,`description`)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='商品表';
|
||
|
||
-- 订单表
|
||
DROP TABLE IF EXISTS `app_order`;
|
||
CREATE TABLE `app_order` (
|
||
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT COMMENT '订单ID',
|
||
`order_no` varchar(50) NOT NULL DEFAULT '' COMMENT '订单号',
|
||
`user_id` bigint(20) unsigned NOT NULL COMMENT '用户ID',
|
||
`product_id` bigint(20) unsigned NOT NULL COMMENT '商品ID',
|
||
`quantity` int(11) NOT NULL DEFAULT '1' COMMENT '数量',
|
||
`price` decimal(10,2) NOT NULL DEFAULT '0.00' COMMENT '单价',
|
||
`amount` decimal(10,2) NOT NULL DEFAULT '0.00' COMMENT '总金额',
|
||
`discount_amount` decimal(10,2) NOT NULL DEFAULT '0.00' COMMENT '优惠金额',
|
||
`final_amount` decimal(10,2) NOT NULL DEFAULT '0.00' COMMENT '实付金额',
|
||
`status` varchar(20) NOT NULL DEFAULT 'pending' COMMENT '订单状态 pending-待付款 paid-已付款 shipped-已发货 completed-已完成 cancelled-已取消',
|
||
`payment_method` varchar(20) NOT NULL DEFAULT '' COMMENT '支付方式',
|
||
`shipping_address` json DEFAULT NULL COMMENT '收货地址JSON',
|
||
`remark` text COMMENT '订单备注',
|
||
`paid_time` datetime DEFAULT NULL COMMENT '支付时间',
|
||
`shipped_time` datetime DEFAULT NULL COMMENT '发货时间',
|
||
`completed_time` datetime DEFAULT NULL COMMENT '完成时间',
|
||
`created_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
|
||
`updated_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
|
||
PRIMARY KEY (`id`),
|
||
UNIQUE KEY `uk_order_no` (`order_no`),
|
||
KEY `idx_user_id` (`user_id`),
|
||
KEY `idx_product_id` (`product_id`),
|
||
KEY `idx_status` (`status`),
|
||
KEY `idx_created_time` (`created_time`),
|
||
KEY `idx_paid_time` (`paid_time`)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='订单表';
|
||
|
||
-- 订单详情表
|
||
DROP TABLE IF EXISTS `app_order_detail`;
|
||
CREATE TABLE `app_order_detail` (
|
||
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT COMMENT 'ID',
|
||
`order_id` bigint(20) unsigned NOT NULL COMMENT '订单ID',
|
||
`product_id` bigint(20) unsigned NOT NULL COMMENT '商品ID',
|
||
`product_title` varchar(200) NOT NULL DEFAULT '' COMMENT '商品标题',
|
||
`product_image` varchar(500) NOT NULL DEFAULT '' COMMENT '商品图片',
|
||
`price` decimal(10,2) NOT NULL DEFAULT '0.00' COMMENT '单价',
|
||
`quantity` int(11) NOT NULL DEFAULT '1' COMMENT '数量',
|
||
`amount` decimal(10,2) NOT NULL DEFAULT '0.00' COMMENT '小计',
|
||
`created_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
|
||
PRIMARY KEY (`id`),
|
||
KEY `idx_order_id` (`order_id`),
|
||
KEY `idx_product_id` (`product_id`)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='订单详情表';
|
||
|
||
-- 支付日志表
|
||
DROP TABLE IF EXISTS `app_payment_log`;
|
||
CREATE TABLE `app_payment_log` (
|
||
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT COMMENT 'ID',
|
||
`user_id` bigint(20) unsigned NOT NULL COMMENT '用户ID',
|
||
`order_id` bigint(20) unsigned DEFAULT NULL COMMENT '订单ID',
|
||
`transaction_id` varchar(100) NOT NULL DEFAULT '' COMMENT '交易ID',
|
||
`type` varchar(20) NOT NULL DEFAULT '' COMMENT '类型 order_payment-订单支付 recharge-充值 refund-退款',
|
||
`amount` decimal(10,2) NOT NULL DEFAULT '0.00' COMMENT '金额',
|
||
`method` varchar(20) NOT NULL DEFAULT '' COMMENT '支付方式 balance-余额 alipay-支付宝 wechat-微信',
|
||
`status` varchar(20) NOT NULL DEFAULT 'pending' COMMENT '状态 pending-处理中 success-成功 failed-失败',
|
||
`description` varchar(255) NOT NULL DEFAULT '' COMMENT '描述',
|
||
`extra_data` json DEFAULT NULL COMMENT '额外数据JSON',
|
||
`created_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
|
||
`updated_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
|
||
PRIMARY KEY (`id`),
|
||
KEY `idx_user_id` (`user_id`),
|
||
KEY `idx_order_id` (`order_id`),
|
||
KEY `idx_transaction_id` (`transaction_id`),
|
||
KEY `idx_type` (`type`),
|
||
KEY `idx_status` (`status`),
|
||
KEY `idx_created_time` (`created_time`)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='支付日志表';
|
||
|
||
-- 转账日志表
|
||
DROP TABLE IF EXISTS `app_transfer_log`;
|
||
CREATE TABLE `app_transfer_log` (
|
||
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT COMMENT 'ID',
|
||
`from_user_id` bigint(20) unsigned NOT NULL COMMENT '转出用户ID',
|
||
`to_user_id` bigint(20) unsigned NOT NULL COMMENT '转入用户ID',
|
||
`amount` decimal(10,2) NOT NULL DEFAULT '0.00' COMMENT '转账金额',
|
||
`type` varchar(20) NOT NULL DEFAULT 'transfer' COMMENT '类型',
|
||
`status` varchar(20) NOT NULL DEFAULT 'success' COMMENT '状态',
|
||
`description` varchar(255) NOT NULL DEFAULT '' COMMENT '描述',
|
||
`created_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
|
||
PRIMARY KEY (`id`),
|
||
KEY `idx_from_user_id` (`from_user_id`),
|
||
KEY `idx_to_user_id` (`to_user_id`),
|
||
KEY `idx_created_time` (`created_time`)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='转账日志表';
|
||
|
||
-- 操作日志表
|
||
DROP TABLE IF EXISTS `app_operation_log`;
|
||
CREATE TABLE `app_operation_log` (
|
||
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT COMMENT 'ID',
|
||
`user_id` bigint(20) unsigned NOT NULL DEFAULT '0' COMMENT '用户ID',
|
||
`module` varchar(50) NOT NULL DEFAULT '' COMMENT '模块',
|
||
`action` varchar(50) NOT NULL DEFAULT '' COMMENT '操作',
|
||
`description` varchar(255) NOT NULL DEFAULT '' COMMENT '描述',
|
||
`ip` varchar(45) NOT NULL DEFAULT '' COMMENT 'IP地址',
|
||
`user_agent` varchar(500) NOT NULL DEFAULT '' COMMENT '用户代理',
|
||
`request_data` json DEFAULT NULL COMMENT '请求数据JSON',
|
||
`response_data` json DEFAULT NULL COMMENT '响应数据JSON',
|
||
`status` tinyint(4) NOT NULL DEFAULT '1' COMMENT '状态 1-成功 0-失败',
|
||
`execution_time` int(11) NOT NULL DEFAULT '0' COMMENT '执行时间(毫秒)',
|
||
`created_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
|
||
PRIMARY KEY (`id`),
|
||
KEY `idx_user_id` (`user_id`),
|
||
KEY `idx_module` (`module`),
|
||
KEY `idx_action` (`action`),
|
||
KEY `idx_created_time` (`created_time`)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='操作日志表';
|
||
|
||
-- 缓存表(HoTimeDB内置缓存使用)
|
||
DROP TABLE IF EXISTS `app_cached`;
|
||
CREATE TABLE `app_cached` (
|
||
`key` varchar(255) NOT NULL COMMENT '缓存键',
|
||
`value` longtext COMMENT '缓存值',
|
||
`expire_time` datetime DEFAULT NULL COMMENT '过期时间',
|
||
`created_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
|
||
`updated_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP COMMENT '更新时间',
|
||
PRIMARY KEY (`key`),
|
||
KEY `idx_expire_time` (`expire_time`)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='缓存表';
|
||
|
||
-- 批量用户表(用于批量操作示例)
|
||
DROP TABLE IF EXISTS `app_user_batch`;
|
||
CREATE TABLE `app_user_batch` (
|
||
`id` bigint(20) unsigned NOT NULL AUTO_INCREMENT COMMENT 'ID',
|
||
`name` varchar(100) NOT NULL DEFAULT '' COMMENT '用户姓名',
|
||
`email` varchar(255) NOT NULL DEFAULT '' COMMENT '邮箱地址',
|
||
`status` tinyint(4) NOT NULL DEFAULT '1' COMMENT '状态',
|
||
`created_time` datetime NOT NULL DEFAULT CURRENT_TIMESTAMP COMMENT '创建时间',
|
||
PRIMARY KEY (`id`),
|
||
KEY `idx_created_time` (`created_time`)
|
||
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_unicode_ci COMMENT='批量用户表';
|
||
|
||
-- 插入测试数据
|
||
INSERT INTO `app_user` (`name`, `email`, `password`, `age`, `level`, `balance`, `status`, `created_time`) VALUES
|
||
('张三', 'zhangsan@example.com', 'hashed_password_1', 25, 'normal', 1000.00, 1, '2023-01-15 10:30:00'),
|
||
('李四', 'lisi@example.com', 'hashed_password_2', 30, 'vip', 5000.00, 1, '2023-02-20 14:20:00'),
|
||
('王五', 'wangwu@example.com', 'hashed_password_3', 28, 'svip', 10000.00, 1, '2023-03-10 16:45:00'),
|
||
('赵六', 'zhaoliu@example.com', 'hashed_password_4', 35, 'normal', 500.00, 1, '2023-04-05 09:15:00'),
|
||
('钱七', 'qianqi@example.com', 'hashed_password_5', 22, 'vip', 2500.00, 0, '2023-05-12 11:30:00');
|
||
|
||
INSERT INTO `app_profile` (`user_id`, `real_name`, `verified`) VALUES
|
||
(1, '张三', 1),
|
||
(2, '李四', 1),
|
||
(3, '王五', 1),
|
||
(4, '赵六', 0),
|
||
(5, '钱七', 0);
|
||
|
||
INSERT INTO `app_department` (`name`, `parent_id`, `description`) VALUES
|
||
('技术部', 0, '负责技术开发和维护'),
|
||
('产品部', 0, '负责产品设计和规划'),
|
||
('市场部', 0, '负责市场推广和销售'),
|
||
('前端组', 1, '负责前端开发'),
|
||
('后端组', 1, '负责后端开发');
|
||
|
||
INSERT INTO `app_product` (`title`, `description`, `price`, `stock`, `category_id`, `brand`, `sales_count`) VALUES
|
||
('苹果手机', '最新款苹果手机,性能强劲', 6999.00, 100, 1, '苹果', 50),
|
||
('华为手机', '国产精品手机,拍照出色', 4999.00, 200, 1, '华为', 80),
|
||
('小米手机', '性价比之王,配置丰富', 2999.00, 300, 1, '小米', 120),
|
||
('联想笔记本', '商务办公首选,稳定可靠', 5999.00, 50, 2, '联想', 30),
|
||
('戴尔笔记本', '游戏性能出色,散热良好', 8999.00, 30, 2, '戴尔', 15);
|
||
|
||
INSERT INTO `app_order` (`order_no`, `user_id`, `product_id`, `quantity`, `price`, `amount`, `final_amount`, `status`, `created_time`) VALUES
|
||
('ORD202301150001', 1, 1, 1, 6999.00, 6999.00, 6999.00, 'paid', '2023-01-15 15:30:00'),
|
||
('ORD202301160001', 2, 2, 2, 4999.00, 9998.00, 9998.00, 'paid', '2023-01-16 10:20:00'),
|
||
('ORD202301170001', 3, 3, 1, 2999.00, 2999.00, 2999.00, 'completed', '2023-01-17 14:15:00'),
|
||
('ORD202301180001', 1, 4, 1, 5999.00, 5999.00, 5999.00, 'pending', '2023-01-18 16:45:00'),
|
||
('ORD202301190001', 4, 5, 1, 8999.00, 8999.00, 8999.00, 'cancelled', '2023-01-19 11:30:00');
|
||
|
||
INSERT INTO `app_order_detail` (`order_id`, `product_id`, `product_title`, `price`, `quantity`, `amount`) VALUES
|
||
(1, 1, '苹果手机', 6999.00, 1, 6999.00),
|
||
(2, 2, '华为手机', 4999.00, 2, 9998.00),
|
||
(3, 3, '小米手机', 2999.00, 1, 2999.00),
|
||
(4, 4, '联想笔记本', 5999.00, 1, 5999.00),
|
||
(5, 5, '戴尔笔记本', 8999.00, 1, 8999.00);
|
||
|
||
INSERT INTO `app_payment_log` (`user_id`, `order_id`, `type`, `amount`, `method`, `status`, `description`) VALUES
|
||
(1, 1, 'order_payment', 6999.00, 'balance', 'success', '订单支付'),
|
||
(2, 2, 'order_payment', 9998.00, 'alipay', 'success', '订单支付'),
|
||
(3, 3, 'order_payment', 2999.00, 'wechat', 'success', '订单支付'),
|
||
(2, NULL, 'recharge', 10000.00, 'alipay', 'success', '账户充值'),
|
||
(3, NULL, 'recharge', 5000.00, 'wechat', 'success', '账户充值');
|
||
|
||
-- 创建索引优化查询性能
|
||
CREATE INDEX idx_user_email_status ON app_user(email, status);
|
||
CREATE INDEX idx_order_user_status ON app_order(user_id, status);
|
||
CREATE INDEX idx_order_created_status ON app_order(created_time, status);
|
||
CREATE INDEX idx_product_category_status ON app_product(category_id, status);
|
||
|
||
-- 创建视图(可选)
|
||
CREATE OR REPLACE VIEW v_user_order_stats AS
|
||
SELECT
|
||
u.id as user_id,
|
||
u.name as user_name,
|
||
u.email,
|
||
u.level,
|
||
COUNT(o.id) as order_count,
|
||
COALESCE(SUM(o.final_amount), 0) as total_amount,
|
||
COALESCE(AVG(o.final_amount), 0) as avg_amount,
|
||
MAX(o.created_time) as last_order_time
|
||
FROM app_user u
|
||
LEFT JOIN app_order o ON u.id = o.user_id AND o.status IN ('paid', 'completed')
|
||
WHERE u.status = 1
|
||
GROUP BY u.id;
|
||
|
||
-- 存储过程示例(可选)
|
||
DELIMITER //
|
||
CREATE PROCEDURE GetUserOrderSummary(IN p_user_id BIGINT)
|
||
BEGIN
|
||
SELECT
|
||
u.name,
|
||
u.email,
|
||
u.level,
|
||
u.balance,
|
||
COUNT(o.id) as order_count,
|
||
COALESCE(SUM(CASE WHEN o.status = 'paid' THEN o.final_amount END), 0) as paid_amount,
|
||
COALESCE(SUM(CASE WHEN o.status = 'completed' THEN o.final_amount END), 0) as completed_amount
|
||
FROM app_user u
|
||
LEFT JOIN app_order o ON u.id = o.user_id
|
||
WHERE u.id = p_user_id AND u.status = 1
|
||
GROUP BY u.id;
|
||
END //
|
||
DELIMITER ;
|
||
|
||
-- 显示表结构信息
|
||
SELECT
|
||
TABLE_NAME as '表名',
|
||
TABLE_COMMENT as '表注释',
|
||
TABLE_ROWS as '预估行数',
|
||
ROUND(DATA_LENGTH/1024/1024, 2) as '数据大小(MB)'
|
||
FROM information_schema.TABLES
|
||
WHERE TABLE_SCHEMA = DATABASE() AND TABLE_NAME LIKE 'app_%'
|
||
ORDER BY TABLE_NAME; |