Commit e0d27b2a by jscat

nyx sql

1. 添加商城类的sql
parent 5bce55cf
USE rockwell_key;
USE rockwell_key;
......@@ -12,11 +12,11 @@ USE rockwell_key;
活动(activity)
问答(quiz) 为 activity 提供题目信息
商品(goods) 为 activity 提供商品 price 和 amount 信息
商品(product) 为 activity 提供商品 price 和 stock 信息
竞答(match) 用 match_id 将 activity_id 同 user_id 联系起来
竞答助力(match_bonus) 将 match_id 同 user_id 联系起来
预订(order) 用 order_id 将 goods_id 同 user_id 联系起来
预订(order) 用 order_id 将 product_id 同 user_id 联系起来
关系如下:
......@@ -73,7 +73,6 @@ CREATE TABLE tbl_activity (
`title` VARCHAR(200) NOT NULL COMMENT '发布标题,比如:此生必去系列。',
`num_like` VARCHAR(10) DEFAULT '0' COMMENT '点赞次数',
`content` VARCHAR(1000) NOT NULL COMMENT '发布内容, 比如: 共10题::可获得5积分 (多个content之间用::来隔开, 未来可考虑json格式)',
`goods` VARCHAR(200) COMMENT '商品列表, 通过::做间隔, gid001::gid002',
`quiz` VARCHAR(200) COMMENT 'quiz题目列表, 通过::做间隔, ',
`point` double(10,2) COMMENT 'quiz 总的积分',
`member_id` VARCHAR(100) COMMENT '商家的id, uuid format, like mid_001',
......@@ -84,14 +83,14 @@ CREATE TABLE tbl_activity (
KEY `query_key` (`member_id`,`tag`, `title`))
ENGINE=INNODB DEFAULT CHARACTER SET utf8 COLLATE utf8_general_ci COMMENT='rockwell member 活动发布表';
INSERT INTO `tbl_activity`(`activity_id`, `tag`, `title`, `num_like`, `content`, `goods`, `quiz`, `point`, `member_id`, `note_image`, `create_datetime`,`update_datetime`)
INSERT INTO `tbl_activity`(`activity_id`, `tag`, `title`, `num_like`, `content`, `quiz`, `point`, `member_id`, `note_image`, `create_datetime`,`update_datetime`)
VALUES
('aid_001', '竞答', 'Renaissance Bar红酒知识竞答', '34', '共5题::可获得5积分', '', '190::191::195::196::299', 5.0, 'mid_123','https://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/%E5%BE%AE%E4%BF%A1%E6%88%AA%E5%9B%BE_20200710174939.png','2020-05-29 16:01:48', '2020-05-29 16:01:48'),
('aid_002', '竞答', 'Renaissance Bar威士忌知识竞答', '100', '共10题::可获得5积分', '', '290::191::195:196::283::201::300::342::355::214', 5.0,'mid_123','https://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/%E5%BE%AE%E4%BF%A1%E6%88%AA%E5%9B%BE_20200710174939.png','2020-05-29 16:01:48', '2020-05-29 16:01:48'),
('aid_003', '竞答', '叁年间知识竞答', '30', '共5题::可获得5积分', '', '199::191::295:236::200', 5.0, 'mid_456','http://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/tmp_a3bb087cd46db1bb054f172b0afd2d32.jpg::http://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/tmp_1cb906383f0d7677b185f423357d2d32.jpg::http://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/tmp_33852ea7dd1dca8aad48b40f39f333ed.jpg::http://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/tmp_82f7406a58e6941b64e117f6980b73f9.jpg::http://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/tmp_655a83d89ae1220ccef8c5f3238c56a4.jpg::http://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/tmp_cdcffb931e7bf35502c93a6f9ec3973e.jpg::http://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/tmp_93f6ac372755b4efc4f0941cd6a8a007.jpg::http://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/tmp_6994cd488ea6bfb1d2e4b478a161cc42.jpg::http://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/tmp_1820c565d261d8e0899f15f62b80a861.jpg', '2020-05-25 14:39:20', '2020-05-25 14:39:20'),
('aid_004', '竞答', 'Cin Cin知识竞答', '10', '共5题::可获得5积分', '', '190::191::195:196::313', 5.0, 'mid_001','http://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/tmp_927aed9aa3b4fb2d857680fae75b76b2.jpg', '2020-05-29 14:48:11','2020-05-29 14:48:11'),
('aid_005', '饮事', 'Renaissance Bar威士忌四小杯特饮活动', '4', '一次领略泥煤的各种风味', 'gid_001::gid_002', '', 0.0, 'mid_123','https://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/sakura.jpg\r\n', '2020-03-27 11:24:45', '2020-03-27 11:24:45'),
('aid_006', '饮事', '叁年间 & 罗翌 意大利红酒周', '10', '叁年间的专业加上罗翌的品质,你值得期待', 'gid_003', '', 0.0, 'mid_456','https://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/sakura.jpg\r\n', '2020-03-27 11:24:45', '2020-03-27 11:24:45')
('aid_001', '竞答', 'Renaissance Bar红酒知识竞答', '34', '共5题::可获得5积分', '190::191::195::196::299', 5.0, 'mid_123','https://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/%E5%BE%AE%E4%BF%A1%E6%88%AA%E5%9B%BE_20200710174939.png','2020-05-29 16:01:48', '2020-05-29 16:01:48'),
('aid_002', '竞答', 'Renaissance Bar威士忌知识竞答', '100', '共10题::可获得5积分', '290::191::195:196::283::201::300::342::355::214', 5.0,'mid_123','https://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/%E5%BE%AE%E4%BF%A1%E6%88%AA%E5%9B%BE_20200710174939.png','2020-05-29 16:01:48', '2020-05-29 16:01:48'),
('aid_003', '竞答', '叁年间知识竞答', '30', '共5题::可获得5积分', '199::191::295:236::200', 5.0, 'mid_456','http://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/tmp_a3bb087cd46db1bb054f172b0afd2d32.jpg::http://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/tmp_1cb906383f0d7677b185f423357d2d32.jpg::http://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/tmp_33852ea7dd1dca8aad48b40f39f333ed.jpg::http://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/tmp_82f7406a58e6941b64e117f6980b73f9.jpg::http://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/tmp_655a83d89ae1220ccef8c5f3238c56a4.jpg::http://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/tmp_cdcffb931e7bf35502c93a6f9ec3973e.jpg::http://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/tmp_93f6ac372755b4efc4f0941cd6a8a007.jpg::http://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/tmp_6994cd488ea6bfb1d2e4b478a161cc42.jpg::http://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/tmp_1820c565d261d8e0899f15f62b80a861.jpg', '2020-05-25 14:39:20', '2020-05-25 14:39:20'),
('aid_004', '竞答', 'Cin Cin知识竞答', '10', '共5题::可获得5积分', '190::191::195:196::313', 5.0, 'mid_001','http://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/tmp_927aed9aa3b4fb2d857680fae75b76b2.jpg', '2020-05-29 14:48:11','2020-05-29 14:48:11'),
('aid_005', '饮事', 'Renaissance Bar威士忌四小杯特饮活动', '4', '一次领略泥煤的各种风味', '', 0.0, 'mid_123','https://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/sakura.jpg', '2020-03-27 11:24:45', '2020-03-27 11:24:45'),
('aid_006', '饮事', '叁年间 & 罗翌 意大利红酒周', '10', '叁年间的专业加上罗翌的品质,你值得期待', '', 0.0, 'mid_456','https://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/sakura.jpg', '2020-03-27 11:24:45', '2020-03-27 11:24:45')
;
USE rockwell_key;
USE rockwell_key;
/*
goods 与 activity 映射表
什么 goods, 属于哪个 activity, 有多少数量,价格多少
activity 和 goods 的关系 1:n 一个 goods 对于多个 activity
比如 一场活动 有两个类别,一个针对会员,一个针对普通用户
*/
DROP TABLE IF EXISTS tbl_goods;
CREATE TABLE tbl_goods(
`goods_id` VARCHAR(100) COMMENT 'goods的id, uuid format',
`goods_status` VARCHAR(10) COMMENT '商品状态: 00:非可售 01:可售',
`goods_desc` VARCHAR(100) COMMENT '商品类别: 描述',
`detail_id` VARCHAR(100) COMMENT '商品的详情id, uuid format',
`price` decimal(10,2) DEFAULT '0.00' COMMENT '价格',
`stock` decimal(10,2) DEFAULT '0.00' COMMENT '库存',
`create_datetime` DATETIME NOT NULL DEFAULT '0000-00-00 00:00:00',
`update_datetime` DATETIME DEFAULT NULL,
PRIMARY KEY(`goods_id`),
KEY `query_key` (`goods_status`))
ENGINE=INNODB DEFAULT CHARACTER SET utf8 COLLATE utf8_general_ci COMMENT='活动所对应的商品名录';
insert into `tbl_goods`(`goods_id`, `goods_status`, `goods_desc`, `detail_id`, `price`, `stock`,
`create_datetime`,`update_datetime`)
values
('gid_001', '01', '会员', '', 59, 10, '2020-05-20 11:24:45', '2020-05-20 11:24:45'),
('gid_002', '01', '普通用户', '', 99, 20, '2020-05-20 11:24:45', '2020-05-20 11:24:45'),
('gid_003', '01', '意大利红酒周', '', 10.5, 10, '2020-05-20 11:24:45', '2020-05-20 11:24:45')
;
USE rockwell_key;
USE rockwell_key;
/*
用于记录预订结果:
1) user 预订一个 activity_id,会生成一条记录 order_id 记录
activity:order = 1:n
order:product = 1:n
关系是 一个活动(activity)对应多个订单(order), 一个订单(order)里有多个品类(product)
记录了如下参数:
- order_id: oid_123
- activity_id: aid_001
- user_id: uid_456
- 订单状态 order_status (可用|不可用): 01|00
- 品类信息 product_info: gid_001::gid_003
- 商品数量 quantity_info: 4::3
- 二维码url qrcode_url: https://930-test-sh.oss-cn-shanghai.aliyuncs.com/qrcode-dir/oid_11235813.png
- 预订时间 create_datetime: 2020/07/30 12:00:00
- 更新时间 update_datetime: 2020/07/30 12:00:00
分布式商城项目数据库设计
https://www.jianshu.com/p/7e673ffb29d8
btw: 按照 in 的顺序排序
SELECT * FROM tbl_product WHERE product_id IN ('gid_002', 'gid_001') ORDER BY FIELD(product_id, 'gid_002', 'gid_001')
*/
DROP TABLE IF EXISTS tbl_order;
CREATE TABLE tbl_order (
`order_id` VARCHAR(100) COMMENT '订单的id, uuid format, mid_001',
`activity_id` VARCHAR(100) COMMENT '活动的id, uuid format, aid_001',
`user_id` VARCHAR(100) COMMENT '用户的id, uuid format, uid_001',
`order_status` VARCHAR(10) DEFAULT '00' COMMENT '订单状态: 00-订单取消, 10-未付款, 20-可使用, 30-已完成',
`payment` DECIMAL(20,2) DEFAULT '0.00' COMMENT '实际付款金额,单位是元,保留两位小数',
`payment_type` VARCHAR(10) DEFAULT '01' COMMENT '支付类型,01-在线支付',
`qrcode_url` VARCHAR(200) COMMENT 'qrcode的二维码url',
`payment_datetime` DATETIME DEFAULT NULL COMMENT '支付时间',
`end_datetime` DATETIME DEFAULT NULL COMMENT '交易完成时间',
`create_datetime` DATETIME NOT NULL DEFAULT '0000-00-00 00:00:00',
`update_datetime` DATETIME DEFAULT NULL,
PRIMARY KEY(`order_id`),
KEY `query_key` (`activity_id`, `user_id`, `order_status`))
ENGINE=INNODB DEFAULT CHARACTER SET utf8 COLLATE utf8_general_ci COMMENT='活动预订结果';
INSERT INTO `tbl_order`(`order_id`, `activity_id`, `user_id`, `order_status`, `payment`, `payment_type`, `qrcode_url`, `payment_datetime`, `end_datetime`, `create_datetime`,`update_datetime`)
VALUES
('oid_001', 'aid_005', 'uid_030e7057-e6b5-4fb0-bcbf-d8bf055e38d9', '20', 217.0, '01', 'https://930-test-sh.oss-cn-shanghai.aliyuncs.com/qrcode-dir/mid_11235813.png', '', '', '2019-11-20 11:24:45', '2019-11-20 11:24:45'),
('oid_002', 'aid_005', 'uid_030e7057-e6b5-4fb0-bcbf-d8bf055e38d9', '10', 0.0, '', '', '', '', '2019-11-20 11:24:45', '2019-11-20 11:24:45'),
('oid_003', 'aid_006', 'uid_030e7057-e6b5-4fb0-bcbf-d8bf055e38d9', '20', 119.0, '01', 'https://930-test-sh.oss-cn-shanghai.aliyuncs.com/qrcode-dir/mid_11235813.png', '', '', '2019-11-20 11:24:45', '2019-11-20 11:24:45')
;
USE rockwell_key;
USE rockwell_key;
/*
用于记录预订结果的子项:
1) user 预订一个 activity_id,会生成一条记录 order_id 记录
一条 order_id 记录 包含多条 order_item_id 记录
每一条 order_item 对应一条 product_id
activity:order = 1:n
order:order_item=1:n
order_item:product = 1:1
关系是
一个活动(activity)对应多个订单(order)
一个订单(order)里有多个子项(order_item)
一个子项(order_item)对应一个品类(product)
记录了如下参数:
- order_id: oid_123
- activity_id: aid_001
- user_id: uid_456
- 订单状态 order_status (可用|不可用): 01|00
- 品类信息 product_info: gid_001::gid_003
- 商品数量 quantity_info: 4::3
- 二维码url qrcode_url: https://930-test-sh.oss-cn-shanghai.aliyuncs.com/qrcode-dir/oid_11235813.png
- 预订时间 create_datetime: 2020/07/30 12:00:00
- 更新时间 update_datetime: 2020/07/30 12:00:00
分布式商城项目数据库设计
https://www.jianshu.com/p/7e673ffb29d8
btw: 按照 in 的顺序排序
SELECT * FROM tbl_product WHERE product_id IN ('gid_002', 'gid_001') ORDER BY FIELD(product_id, 'gid_002', 'gid_001')
*/
DROP TABLE IF EXISTS tbl_order_item;
CREATE TABLE tbl_order_item (
`item_id` VARCHAR(100) COMMENT '子项的id, uuid format, iid_001',
`order_id` VARCHAR(100) COMMENT '订单的id, uuid format, oid_001',
`user_id` VARCHAR(100) COMMENT '用户的id, uuid format, uid_001',
`product_id` VARCHAR(100) COMMENT '商品的id, uuid format, pid_001',
`product_desc` VARCHAR(100) COMMENT '商品的名称',
`product_image` VARCHAR(500) COMMENT '商品的图片地址',
`unit_price` decimal(20,2) DEFAULT '0.00' COMMENT '生成订单时的商品单价,单位是元,保留两位小数',
`quantity` int(10) DEFAULT 0 COMMENT '商品数量',
`total_price` decimal(20,2) DEFAULT '0.00' COMMENT '商品总价,单位是元,保留两位小数',
`create_datetime` DATETIME NOT NULL DEFAULT '0000-00-00 00:00:00',
`update_datetime` DATETIME DEFAULT NULL,
PRIMARY KEY(`item_id`),
KEY `query_key` (`order_id`, `user_id`, `product_id`))
ENGINE=INNODB DEFAULT CHARACTER SET utf8 COLLATE utf8_general_ci COMMENT='活动预订结果的子项';
INSERT INTO `tbl_order_item`(`item_id`, `order_id`, `user_id`, `product_id`, `product_desc`, `unit_price`, `quantity`, `total_price`, `product_image`, `create_datetime`,`update_datetime`)
VALUES
('iid_001', 'oid_001', 'uid_030e7057-e6b5-4fb0-bcbf-d8bf055e38d9', 'pid_001', "会员", 59.0, 2, 118.0, 'https://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/sakura.jpg', '2019-11-20 11:24:45', '2019-11-20 11:24:45'),
('iid_002', 'oid_001', 'uid_030e7057-e6b5-4fb0-bcbf-d8bf055e38d9', 'pid_002', "普通用户", 99.0, 1, 99.0, 'https://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/sakura.jpg', '2019-11-20 11:24:45', '2019-11-20 11:24:45'),
('iid_003', 'oid_002', 'uid_030e7057-e6b5-4fb0-bcbf-d8bf055e38d9', 'pid_001', "会员", 59.0, 1, 59.0, 'https://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/sakura.jpg', '2019-11-20 11:24:45', '2019-11-20 11:24:45'),
('iid_004', 'oid_003', 'uid_030e7057-e6b5-4fb0-bcbf-d8bf055e38d9', 'pid_003', "意大利红酒周", 119.0, 1, 119.0, 'https://930-test-sh.oss-cn-shanghai.aliyuncs.com/user-dir/sakura.jpg', '2019-11-20 11:24:45', '2019-11-20 11:24:45')
;
USE rockwell_key;
USE rockwell_key;
/*
用于记录支付结果:
与order表一一对应
*/
DROP TABLE IF EXISTS tbl_pay_info;
CREATE TABLE tbl_pay_info (
`pay_id` VARCHAR(100) COMMENT '支付的id, uuid format, pid_001',
`order_id` VARCHAR(100) COMMENT '订单的id, uuid format, oid_001',
`user_id` VARCHAR(100) COMMENT '用户的id, uuid format, uid_001',
`pay_platform` VARCHAR(10) DEFAULT NULL COMMENT '支付平台, 10-微信; 20-支付宝',
`pay_number` VARCHAR(200) DEFAULT NULL COMMENT '支付流水号',
`pay_status` VARCHAR(20) DEFAULT '00' COMMENT '支付状态: 00-未完成; 01-已完成',
`create_datetime` DATETIME NOT NULL DEFAULT '0000-00-00 00:00:00',
`update_datetime` DATETIME DEFAULT NULL,
PRIMARY KEY(`pay_id`),
KEY `query_key` (`order_id`, `user_id`, `pay_status`))
ENGINE=INNODB DEFAULT CHARACTER SET utf8 COLLATE utf8_general_ci COMMENT='支付信息表';
INSERT INTO `tbl_pay_info`(`pay_id`, `order_id`, `user_id`, `pay_platform`, `pay_number`, `pay_status`, `create_datetime`,`update_datetime`)
VALUES
('piid_001', 'oid_001', 'uid_030e7057-e6b5-4fb0-bcbf-d8bf055e38d9', '10', 'pay_001', '01', '2019-11-20 11:24:45', '2019-11-20 11:24:45'),
('piid_002', 'oid_002', 'uid_030e7057-e6b5-4fb0-bcbf-d8bf055e38d9', NULL, NULL, '00', '2019-11-20 11:24:45', '2019-11-20 11:24:45'),
('piid_003', 'oid_003', 'uid_030e7057-e6b5-4fb0-bcbf-d8bf055e38d9', '10', 'pay_001', '01', '2019-11-20 11:24:45', '2019-11-20 11:24:45')
;
USE rockwell_key;
USE rockwell_key;
/*
product 与 activity 映射表
什么 product, 属于哪个 activity, 有多少数量,价格多少
activity 和 product 的关系 1:n 一个 activity 对于多个 product
比如 一场活动 有两个类别,一个针对会员,一个针对普通用户
注意库存管理 stock
参考1: 分布式商城项目数据库设计
https://www.jianshu.com/p/7e673ffb29d8
参考2: 购物车与下订单项目总结
https://blog.csdn.net/kusedexingfu/article/details/35571065
*/
DROP TABLE IF EXISTS tbl_product;
CREATE TABLE tbl_product(
`product_id` VARCHAR(100) COMMENT 'product的id, uuid format',
`activity_id` VARCHAR(100) COMMENT 'activity的id, uuid format',
`product_status` VARCHAR(10) DEFAULT '00' COMMENT '商品状态: 00:非可售 01:可售',
`product_desc` VARCHAR(100) COMMENT '类别说明',
`price` decimal(10,2) DEFAULT '0.00' COMMENT '价格',
`stock` int(11) DEFAULT 0 COMMENT '库存数量',
`create_datetime` DATETIME NOT NULL DEFAULT '0000-00-00 00:00:00',
`update_datetime` DATETIME DEFAULT NULL,
PRIMARY KEY(`product_id`),
KEY `query_key` (`activity_id`, `product_status`))
ENGINE=INNODB DEFAULT CHARACTER SET utf8 COLLATE utf8_general_ci COMMENT='活动所对应的商品名录';
insert into `tbl_product`(`product_id`, `activity_id`, `product_status`, `product_desc`, `price`, `stock`,
`create_datetime`,`update_datetime`)
values
('pid_001', 'aid_005', '01', '会员', 59, 10, '2020-05-20 11:24:45', '2020-05-20 11:24:45'),
('pid_002', 'aid_005', '01', '普通用户', 99, 20, '2020-05-20 11:24:45', '2020-05-20 11:24:45'),
('pid_003', 'aid_006', '01', '意大利红酒周', 199, 10, '2020-05-20 11:24:45', '2020-05-20 11:24:45')
;
Markdown 格式
0%
您添加了 0 到此讨论。请谨慎行事。
请先完成此评论的编辑!
注册 或者 后发表评论