- 创建DB
[root@XAG816 ~]# mysql.login
root@127.0.0.1 : (none)【10:14:13】2 SQL->show databases;
+--------------------+
| Database |
+--------------------+
| information_schema |
| mysql |
| performance_schema |
| sys |
+--------------------+
root@127.0.0.1 : (none)【10:14:22】3 SQL->CREATE DATABASE TESTDB;
- 创建表
root@127.0.0.1 : (none)【10:34:15】1 SQL->use testdb
root@127.0.0.1 : testdb【10:34:23】3 SQL->show tables;
Empty set (0.01 sec)
root@127.0.0.1 : testdb【10:37:24】4 SQL->create table emp(ename varchar(10),hiredate date,sal decimal(10,2),deptno int(2));
root@127.0.0.1 : testdb【10:37:36】5 SQL->desc emp;
+----------+---------------+------+-----+---------+-------+
| Field | Type | Null | Key | Default | Extra |
+----------+---------------+------+-----+---------+-------+
| ename | varchar(10) | YES | | NULL | |
| hiredate | date | YES | | NULL | |
| sal | decimal(10,2) | YES | | NULL | |
| deptno | int(2) | YES | | NULL | |
+----------+---------------+------+-----+---------+-------+
root@127.0.0.1 : testdb【10:37:53】6 SQL->show create table emp \G;
*************************** 1. row ***************************
Table: emp
Create Table: CREATE TABLE `emp` (
`ename` varchar(10) DEFAULT NULL,
`hiredate` date DEFAULT NULL,
`sal` decimal(10,2) DEFAULT NULL,
`deptno` int(2) DEFAULT NULL
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci
root@127.0.0.1 : testdb【10:38:18】7 SQL->alter table emp modify ename varchar(20);
root@127.0.0.1 : testdb【10:38:39】8 SQL->alter table emp add column age int(3);
root@127.0.0.1 : testdb【10:38:53】9 SQL->alter table emp drop column age;
root@127.0.0.1 : testdb【10:39:46】11 SQL->alter table emp change hiredate hiredate_new date;
root@127.0.0.1 : testdb【10:40:36】12 SQL->alter table emp add birth date after ename;
root@127.0.0.1 : testdb【10:41:23】14 SQL->alter table emp add column age int(3);
root@127.0.0.1 : testdb【10:41:44】15 SQL->alter table emp modify age int(3) first;
root@127.0.0.1 : testdb【10:41:49】16 SQL->alter table emp rename emp1;
root@127.0.0.1 : testdb【10:42:17】18 SQL->show create table emp1 \G;
*************************** 1. row ***************************
Table: emp1
Create Table: CREATE TABLE `emp1` (
`age` int(3) DEFAULT NULL,
`ename` varchar(20) DEFAULT NULL,
`birth` date DEFAULT NULL,
`hiredate_new` date DEFAULT NULL,
`sal` decimal(10,2) DEFAULT NULL,
`deptno` int(2) DEFAULT NULL
) ENGINE=InnoDB DEFAULT CHARSET=utf8mb4 COLLATE=utf8mb4_0900_ai_ci
root@127.0.0.1 : testdb【10:42:25】19 SQL->desc emp1;
+--------------+---------------+------+-----+---------+-------+
| Field | Type | Null | Key | Default | Extra |
+--------------+---------------+------+-----+---------+-------+
| age | int(3) | YES | | NULL | |
| ename | varchar(20) | YES | | NULL | |
| birth | date | YES | | NULL | |
| hiredate_new | date | YES | | NULL | |
| sal | decimal(10,2) | YES | | NULL | |
| deptno | int(2) | YES | | NULL | |
+--------------+---------------+------+-----+---------+-------+
- DML 语句
root@127.0.0.1 : testdb【10:47:29】23 SQL->create table emp(ename varchar(10),hiredate date,sal decimal(10,2),deptno int(2));
root@127.0.0.1 : testdb【10:47:31】24 SQL->create table dept(deptno int(2),deptname varchar(10));
root@127.0.0.1 : testdb【10:49:48】28 SQL->insert into emp(ename,hiredate,sal,deptno) values('xag1','1978-03-01',1000,1),('xag2','1978-03-02',2000,2);
root@127.0.0.1 : testdb【10:49:50】29 SQL->insert into dept(deptno,deptname ) values(1,'aa'),(2,'bb'),(3,'cc');
root@127.0.0.1 : testdb【10:51:00】30 SQL->select * from emp;
+-------+------------+---------+--------+
| ename | hiredate | sal | deptno |
+-------+------------+---------+--------+
| xag1 | 1978-03-01 | 1000.00 | 1 |
| xag2 | 1978-03-02 | 2000.00 | 2 |
+-------+------------+---------+--------+
root@127.0.0.1 : testdb【10:51:45】31 SQL->select * from dept;
+--------+----------+
| deptno | deptname |
+--------+----------+
| 1 | aa |
| 2 | bb |
| 3 | cc |
+--------+----------+
root@127.0.0.1 : testdb【10:51:53】32 SQL->update emp a,dept b set a.sal=a.sal*b.deptno,b.deptname=a.ename where a.deptno=b.deptno;
root@127.0.0.1 : testdb【10:51:58】33 SQL->select * from emp;
+-------+------------+---------+--------+
| ename | hiredate | sal | deptno |
+-------+------------+---------+--------+
| xag1 | 1978-03-01 | 1000.00 | 1 |
| xag2 | 1978-03-02 | 4000.00 | 2 |
+-------+------------+---------+--------+
root@127.0.0.1 : testdb【10:52:04】34 SQL->select * from dept;
+--------+----------+
| deptno | deptname |
+--------+----------+
| 1 | xag1 |
| 2 | xag2 |
| 3 | cc |
+--------+----------+
#查询从第二条记录开始的2条记录(0表示第1条,1表示第二条)
root@127.0.0.1 : testdb【10:52:15】35 SQL->select * from dept order by deptno desc limit 1,2;
+--------+----------+
| deptno | deptname |
+--------+----------+
| 2 | xag2 |
| 1 | xag1 |
+--------+----------+
#按部门统计同时统计合计数
root@127.0.0.1 : testdb【10:53:43】36 SQL->select deptno,count(1) from emp group by deptno with rollup;
+--------+----------+
| deptno | count(1) |
+--------+----------+
| 1 | 1 |
| 2 | 1 |
| NULL | 2 |
+--------+----------+
- 创建自增量的字段的表
root@127.0.0.1 : testdb【10:54:24】37 SQL->
create table mp_user
(
mp_user_seq int auto_increment not null,
mp_user_name varchar(20),
primary key(mp_user_seq)
) ;
root@127.0.0.1 : testdb【11:01:22】40 SQL->alter table mp_user auto_increment=100;
#OR
root@127.0.0.1 : testdb【11:01:57】43 SQL->drop table mp_user;
root@127.0.0.1 : testdb【11:02:19】44 SQL->
create table mp_user
(
mp_user_seq int auto_increment not null,
mp_user_name varchar(20),
primary key(mp_user_seq)
) auto_increment=100;
# last_insert_id() 查询当前线程最后一次插入记录使用的值(如果一次插入多个值则返回首条插入记录使用的自动增长值);
root@127.0.0.1 : testdb【12:23:23】18 SQL->insert mp_user(mp_user_name) values('a1');
root@127.0.0.1 : testdb【12:23:28】19 SQL->select last_insert_id();
+------------------+
| last_insert_id() |
+------------------+
| 100 |
+------------------+
root@127.0.0.1 : testdb【12:23:37】20 SQL->insert mp_user(mp_user_name) values('a2'),('a3'),('a4');
root@127.0.0.1 : testdb【12:24:11】21 SQL->select last_insert_id();
+------------------+
| last_insert_id() |
+------------------+
| 101 |
+------------------+
#2
create table my_account
(
acc_seq int auto_increment not null,
acc_no varchar(20),
acc_name varchar(50),
acc_banance decimal(12,2),
acc_createtime datetime,
acc_update datetime,
primary key(acc_seq)
) auto_increment=1001;
alter table my_account add unique(acc_no);
#3
create table my_account_tran
(
tran_seq int auto_increment not null,
acc_no varchar(20),
tran_no varchar(30),
tran_money decimal(10,2),
tran_time datetime,
primary key(tran_seq)
) auto_increment=1001;
alter table my_account_tran add unique(tran_no);
alter table my_account_tran add constraint ck_tran_money check(tran_money between -1000 and 1000);
insert into my_account_tran(acc_no,tran_no,tran_money,tran_time) values('c1001','20160619100001',100,now());
#4 (此版捕获所有异常)
CREATE TABLE tb_log (errorno int,errortext TEXT,error_timestamp DATETIME);
DROP PROCEDURE IF EXISTS proc_my_acc_rollback2;
DELIMITER $$
CREATE PROCEDURE proc_my_acc_rollback2
(
in v_acc_no VARCHAR(20),
in v_acc_name varchar(50),
in v_tran_no varchar(30),
in v_tran_money DECIMAL(10,2),
out v_return varchar(500)
)
BEGIN
DECLARE v_now datetime;
DECLARE i TINYINT DEFAULT 1;
DECLARE v_errcount INT DEFAULT 0; /**获取一次错误数据条数 */
DECLARE v_errno INT DEFAULT 0;/**获取错误代码*/
DECLARE v_msg TEXT;/**获取错误详细信息*/
DECLARE CONTINUE HANDLER FOR SQLEXCEPTION /**定义一个异常处理块*/
BEGIN
get stacked diagnostics v_errcount = number;
set i=1;
WHILE i <= v_errcount
DO
GET stacked DIAGNOSTICS CONDITION i v_errno = MYSQL_ERRNO, v_msg = MESSAGE_TEXT;
SET v_return = CONCAT(v_return,v_errno);
SET v_return = CONCAT(v_return,':');
SET v_return = CONCAT(v_return,v_msg);
SET v_return = CONCAT(v_return,'; ');
SET i = i + 1;
END WHILE;
END;
/** 显式的开启事务,它开启后,事务会暂时停止自动提交*/
-- start transaction;
/** 关闭事务的自动提交 */
SET autocommit = 0;
SET v_return='[proc_my_acc_rollback2 err:] ';
insert into my_account_tran(acc_no,tran_no,tran_money,tran_time)
values(v_acc_no,v_tran_no,v_tran_money,v_now);
/**IF v_errcount=0 THEN */
/* 注释掉上面if 语句表示 报错后继续运行,最后捕获所以异常,否则 出现第一个异常后就退出,仅仅能捕获第一个异常 */
insert into my_account(acc_no,acc_name,acc_banance,acc_createtime)
values(v_acc_no,v_acc_name,v_tran_money,v_now);
/*END IF; */
/** 标记被改变,表示事务应该回滚 */
IF v_errcount>0 THEN
ROLLBACK; -- 事务回滚
SET autocommit =1;
INSERT INTO tb_log VALUES (v_errno,v_return,NOW());
ELSE
COMMIT; -- 事务提交
SET autocommit =1;
SET v_return='[OK]';
END IF;
END$$
DELIMITER ;
#5 没问题版(此版捕获第一个异常)
DROP PROCEDURE IF EXISTS proc_my_acc_rollback3;
DELIMITER $$
CREATE PROCEDURE proc_my_acc_rollback3
(
in v_acc_no VARCHAR(20),
in v_acc_name varchar(50),
in v_tran_no varchar(30),
in v_tran_money DECIMAL(10,2),
out v_return varchar(500)
)
BEGIN
DECLARE v_now datetime;
DECLARE i TINYINT DEFAULT 1;
DECLARE v_errcount INT DEFAULT 0; /**获取一次错误数据条数 */
DECLARE v_errno INT DEFAULT 0;/**获取错误代码*/
DECLARE v_msg TEXT;/**获取错误详细信息*/
DECLARE CONTINUE HANDLER FOR SQLEXCEPTION /**定义一个异常处理块*/
BEGIN
get stacked diagnostics v_errcount = number;
set i=1;
WHILE i <= v_errcount
DO
GET stacked DIAGNOSTICS CONDITION i v_errno = MYSQL_ERRNO, v_msg = MESSAGE_TEXT;
SET v_return = CONCAT(v_return,v_errno);
SET v_return = CONCAT(v_return,':');
SET v_return = CONCAT(v_return,v_msg);
SET v_return = CONCAT(v_return,'; ');
SET i = i + 1;
END WHILE;
END;
/** 显式的开启事务,它开启后,事务会暂时停止自动提交*/
-- start transaction;
/** 关闭事务的自动提交 */
SET autocommit = 0;
SET v_return='[proc_my_acc_rollback3 err:] ';
insert into my_account_tran(acc_no,tran_no,tran_money,tran_time)
values(v_acc_no,v_tran_no,v_tran_money,v_now);
IF v_errcount=0 THEN
/* 注释掉上面if 语句表示 报错后继续运行,最后捕获所以异常,否则 出现第一个异常后就退出,仅仅能捕获第一个异常 */
insert into my_account(acc_no,acc_name,acc_banance,acc_createtime)
values(v_acc_no,v_acc_name,v_tran_money,v_now);
END IF;
/** 标记被改变,表示事务应该回滚 */
IF v_errcount>0 THEN
ROLLBACK; -- 事务回滚
SET autocommit =1;
INSERT INTO tb_log VALUES (v_errno,v_return,NOW());
ELSE
COMMIT; -- 事务提交
SET autocommit =1;
SET v_return='[OK]';
END IF;
END$$
DELIMITER ;
#6测试案例
root@127.0.0.1 : testdb【11:21:58】128 SQL-> delete from my_account_tran;
root@127.0.0.1 : testdb【11:22:42】129 SQL-> delete from my_account;
-- 交易编号重复&账号重复 测试
root@127.0.0.1 : testdb【11:37:09】198 SQL-> call proc_my_acc_rollback2('c1002','xag2','20160702100002',100,@msg);
root@127.0.0.1 : testdb【11:37:11】199 SQL-> select @msg;
+------+
| @msg |
+------+
| [OK] |
+------+
root@127.0.0.1 : testdb【11:37:20】200 SQL->select * from tb_log;
Empty set (0.00 sec)
root@127.0.0.1 : testdb【11:39:32】202 SQL->call proc_my_acc_rollback2('c1002','xag2','20160702100002',100,@msg);
root@127.0.0.1 : testdb【11:39:36】203 SQL->select @msg;
+---------------------------------------------------------------------------------------------------------------------------------------+
| @msg |
+---------------------------------------------------------------------------------------------------------------------------------------+
| [proc_my_acc_rollback2 err:] 1062:Duplicate entry '20160702100002' for key 'tran_no'; 1062:Duplicate entry 'c1002' for key 'acc_no'; |
+---------------------------------------------------------------------------------------------------------------------------------------+
root@127.0.0.1 : testdb【11:39:46】204 SQL->select * from tb_log;
+---------+---------------------------------------------------------------------------------------------------------------------------------------+---------------------+
| errorno | errortext | error_timestamp |
+---------+---------------------------------------------------------------------------------------------------------------------------------------+---------------------+
| 1062 | [proc_my_acc_rollback2 err:] 1062:Duplicate entry '20160702100002' for key 'tran_no'; 1062:Duplicate entry 'c1002' for key 'acc_no'; | 2019-07-11 23:39:36 |
+---------+---------------------------------------------------------------------------------------------------------------------------------------+---------------------+
--账号重复 测试
call proc_my_acc_rollback2('c1002','xag2','20160702100003',100,@msg);
root@127.0.0.1 : testdb【11:41:14】209 SQL->select @msg;
+------------------------------------------------------------------------------+
| @msg |
+------------------------------------------------------------------------------+
| [proc_my_acc_rollback2 err:] 1062:Duplicate entry 'c1002' for key 'acc_no'; |
+------------------------------------------------------------------------------+
--金额超限
call proc_my_acc_rollback2('c1003','xag3','20160702100003',2000,@msg);
root@127.0.0.1 : testdb【11:53:03】252 SQL->select @msg;
+-----------------------------------------------------------------------------------+
| @msg |
+-----------------------------------------------------------------------------------+
| [proc_my_acc_rollback2 err:] 3819:Check constraint 'ck_tran_money' is violated.; |
+-----------------------------------------------------------------------------------+
-- 成功插入 测试
call proc_my_acc_rollback2('c1003','xag3','20160702100003',100,@msg);
root@127.0.0.1 : testdb【11:42:34】213 SQL->select @msg;
+------+
| @msg |
+------+
| [OK] |
+------+
#7 测试案例
root@127.0.0.1 : testdb【11:43:26】216 SQL->delete from my_account_tran;
root@127.0.0.1 : testdb【11:43:28】217 SQL->delete from my_account;
root@127.0.0.1 : testdb【11:43:35】218 SQL->delete from tb_log;
-- 交易编号重复&账号重复 测试
call proc_my_acc_rollback3('c1002','xag2','20160702100002',100,@msg);
root@127.0.0.1 : testdb【11:44:55】220 SQL->select @msg;
+------+
| @msg |
+------+
| [OK] |
+------+
root@127.0.0.1 : testdb【11:45:22】223 SQL->call proc_my_acc_rollback3('c1002','xag2','20160702100002',100,@msg);
root@127.0.0.1 : testdb【11:45:25】224 SQL->select @msg;
+----------------------------------------------------------------------------------------+
| @msg |
+----------------------------------------------------------------------------------------+
| [proc_my_acc_rollback3 err:] 1062:Duplicate entry '20160702100002' for key 'tran_no'; |
+----------------------------------------------------------------------------------------+
root@127.0.0.1 : testdb【11:45:29】225 SQL->select * from tb_log;
+---------+----------------------------------------------------------------------------------------+---------------------+
| errorno | errortext | error_timestamp |
+---------+----------------------------------------------------------------------------------------+---------------------+
| 1062 | [proc_my_acc_rollback3 err:] 1062:Duplicate entry '20160702100002' for key 'tran_no'; | 2019-07-11 23:45:25 |
--账号重复 测试
call proc_my_acc_rollback3('c1002','xag2','20160702100003',100,@msg);
root@127.0.0.1 : testdb【11:47:12】229 SQL->select @msg;
+------------------------------------------------------------------------------+
| @msg |
+------------------------------------------------------------------------------+
| [proc_my_acc_rollback3 err:] 1062:Duplicate entry 'c1002' for key 'acc_no'; |
--交易编号重复测试
call proc_my_acc_rollback3('c1003','xag3','20160702100002',100,@msg);
root@127.0.0.1 : testdb【11:49:17】231 SQL->select @msg;
+----------------------------------------------------------------------------------------+
| @msg |
+----------------------------------------------------------------------------------------+
| [proc_my_acc_rollback3 err:] 1062:Duplicate entry '20160702100002' for key 'tran_no'; |
+----------------------------------------------------------------------------------------+
--金额超限
call proc_my_acc_rollback3('c1003','xag3','20160702100003',2000,@msg);
root@127.0.0.1 : testdb【11:51:53】237 SQL->select @msg;
+-----------------------------------------------------------------------------------+
| @msg |
+-----------------------------------------------------------------------------------+
| [proc_my_acc_rollback3 err:] 3819:Check constraint 'ck_tran_money' is violated.; |
+-----------------------------------------------------------------------------------+
-- 成功插入 测试
call proc_my_acc_rollback3('c1003','xag3','20160702100003',100,@msg);
root@127.0.0.1 : testdb【11:53:43】258 SQL->select @msg;
+------+
| @msg |
+------+
| [OK] |
+------+
root@127.0.0.1 : testdb【11:53:46】259 SQL->select * from my_account_tran;
+----------+--------+----------------+------------+-----------+
| tran_seq | acc_no | tran_no | tran_money | tran_time |
+----------+--------+----------------+------------+-----------+
| 1011 | c1002 | 20160702100002 | 100.00 | NULL |
| 1015 | c1003 | 20160702100003 | 100.00 | NULL |
+----------+--------+----------------+------------+-----------+
root@127.0.0.1 : testdb【11:53:51】260 SQL->select * from my_account;
+---------+--------+----------+-------------+----------------+------------+
| acc_seq | acc_no | acc_name | acc_banance | acc_createtime | acc_update |
+---------+--------+----------+-------------+----------------+------------+
| 1010 | c1002 | xag2 | 100.00 | NULL | NULL |
| 1013 | c1003 | xag3 | 100.00 | NULL | NULL |
+---------+--------+----------+-------------+----------------+------------+