From 642525b9ad92f0b7f928e83600d493e6b2363d64 Mon Sep 17 00:00:00 2001 From: Aleksey Midenkov Date: Fri, 28 Apr 2017 09:46:00 +0300 Subject: [PATCH] Tests: cte_recursive, simple (new plans) Author: Alvin Richards --- .../suite/versioning/r/cte_recursive.result | 68 ++++++++++++++++++ mysql-test/suite/versioning/r/simple.result | 71 +++++++++++++++++++ .../suite/versioning/t/cte_recursive.opt | 1 + .../suite/versioning/t/cte_recursive.test | 69 ++++++++++++++++++ mysql-test/suite/versioning/t/simple.opt | 1 + mysql-test/suite/versioning/t/simple.test | 70 ++++++++++++++++++ 6 files changed, 280 insertions(+) create mode 100644 mysql-test/suite/versioning/r/cte_recursive.result create mode 100644 mysql-test/suite/versioning/r/simple.result create mode 100644 mysql-test/suite/versioning/t/cte_recursive.opt create mode 100644 mysql-test/suite/versioning/t/cte_recursive.test create mode 100644 mysql-test/suite/versioning/t/simple.opt create mode 100644 mysql-test/suite/versioning/t/simple.test diff --git a/mysql-test/suite/versioning/r/cte_recursive.result b/mysql-test/suite/versioning/r/cte_recursive.result new file mode 100644 index 00000000000..91f95e561e3 --- /dev/null +++ b/mysql-test/suite/versioning/r/cte_recursive.result @@ -0,0 +1,68 @@ +create or replace table dept ( +dept_id int(10) primary key, +name varchar(100) +) +with system versioning; +create or replace table emp ( +emp_id int(10) primary key, +dept_id int(10) not null, +name varchar(100) not null, +mgr int(10), +salary int(10) not null, +constraint `dept-emp-fk` + foreign key (dept_id) references dept (dept_id) +on delete cascade +on update restrict, +constraint `mgr-fk` + foreign key (mgr) references emp (emp_id) +on delete restrict +on update restrict +) +with system versioning; +insert into dept (dept_id, name) values (10, "accounting"); +insert into emp (emp_id, name, salary, dept_id, mgr) values +(1, "bill", 1000, 10, null), +(20, "john", 500, 10, 1), +(30, "jane", 750, 10,1 ); +select vtq_commit_ts(max(sys_trx_start)) into @ts_1 from emp; +update emp set mgr=30 where name ="john"; +select vtq_commit_ts(sys_trx_start) into @ts_2 from emp where name="john"; +/* All report to 'Bill' */ +with recursive +ancestors +as +( +select e.emp_id, e.name, e.mgr, e.salary +from emp as e for system_time as of timestamp @ts_1 +where name = 'bill' + union +select e.emp_id, e.name, e.mgr, e.salary +from emp as e for system_time as of timestamp @ts_1, +ancestors as a +where e.mgr = a.emp_id +) +select * from ancestors; +emp_id name mgr salary +1 bill NULL 1000 +30 jane 1 750 +/* Expected 3 rows */ +with recursive +ancestors +as +( +select e.emp_id, e.name, e.mgr, e.salary +from emp as e for system_time as of timestamp @ts_2 +where name = 'bill' + union +select e.emp_id, e.name, e.mgr, e.salary +from emp as e for system_time as of timestamp @ts_2, +ancestors as a +where e.mgr = a.emp_id +) +select * from ancestors for system_time as of timestamp @ts_2; +emp_id name mgr salary +1 bill NULL 1000 +30 jane 1 750 +20 john 30 500 +drop table emp; +drop table dept; diff --git a/mysql-test/suite/versioning/r/simple.result b/mysql-test/suite/versioning/r/simple.result new file mode 100644 index 00000000000..9454d487293 --- /dev/null +++ b/mysql-test/suite/versioning/r/simple.result @@ -0,0 +1,71 @@ +create or replace table dept ( +dept_id int(10) primary key, +name varchar(100) +) +with system versioning; +create or replace table emp ( +emp_id int(10) primary key, +dept_id int(10), +name varchar(100), +salary int(10), +constraint `dept-emp-fk` + foreign key (dept_id) references dept (dept_id) +on delete cascade +on update restrict +) +with system versioning; +select now() into @ts_0; +insert into dept (dept_id, name) values (10, "accounting"); +commit; +select vtq_commit_ts(sys_trx_start) into @ts_1 from dept where dept_id=10; +insert into emp (emp_id, name, salary, dept_id) values (1, "bill", 1000, 10); +commit; +select vtq_commit_ts(sys_trx_start) into @ts_2 from emp where name="bill"; +select * from emp; +emp_id dept_id name salary +1 10 bill 1000 +update emp set salary=2000 where name="bill"; +commit; +select vtq_commit_ts(sys_trx_start) into @ts_3 from emp where name="bill"; +select * from emp; +emp_id dept_id name salary +1 10 bill 2000 +select * from emp for system_time as of timestamp @ts_2; +emp_id dept_id name salary +1 10 bill 1000 +select * from emp for system_time as of timestamp @ts_3; +emp_id dept_id name salary +1 10 bill 2000 +select * from emp e, dept d +where d.dept_id = 10 +and d.dept_id = e.dept_id; +emp_id dept_id name salary dept_id name +1 10 bill 2000 10 accounting +select * from emp e, dept d +where d.dept_id = 10 +and d.dept_id = e.dept_id +query for system_time from timestamp @ts_1 to timestamp @ts_2; +emp_id dept_id name salary sys_trx_start sys_trx_end dept_id name sys_trx_start sys_trx_end +select * from emp e, dept d +where d.dept_id = 10 +and d.dept_id = e.dept_id +query for system_time as of timestamp @ts_0; +emp_id dept_id name salary dept_id name +select * from emp e, dept d +where d.dept_id = 10 +and d.dept_id = e.dept_id +query for system_time as of timestamp @ts_1; +emp_id dept_id name salary dept_id name +select * from emp e, dept d +where d.dept_id = 10 +and d.dept_id = e.dept_id +query for system_time as of timestamp @ts_2; +emp_id dept_id name salary dept_id name +1 10 bill 1000 10 accounting +select * from emp e, dept d +where d.dept_id = 10 +and d.dept_id = e.dept_id +query for system_time as of timestamp @ts_3; +emp_id dept_id name salary dept_id name +1 10 bill 2000 10 accounting +drop table emp, dept; diff --git a/mysql-test/suite/versioning/t/cte_recursive.opt b/mysql-test/suite/versioning/t/cte_recursive.opt new file mode 100644 index 00000000000..3596fc4d3bd --- /dev/null +++ b/mysql-test/suite/versioning/t/cte_recursive.opt @@ -0,0 +1 @@ +--innodb --default-storage-engine=innodb diff --git a/mysql-test/suite/versioning/t/cte_recursive.test b/mysql-test/suite/versioning/t/cte_recursive.test new file mode 100644 index 00000000000..fcddb5971e7 --- /dev/null +++ b/mysql-test/suite/versioning/t/cte_recursive.test @@ -0,0 +1,69 @@ +create or replace table dept ( + dept_id int(10) primary key, + name varchar(100) +) +with system versioning; + +create or replace table emp ( + emp_id int(10) primary key, + dept_id int(10) not null, + name varchar(100) not null, + mgr int(10), + salary int(10) not null, + constraint `dept-emp-fk` + foreign key (dept_id) references dept (dept_id) + on delete cascade + on update restrict, + constraint `mgr-fk` + foreign key (mgr) references emp (emp_id) + on delete restrict + on update restrict +) +with system versioning; + +insert into dept (dept_id, name) values (10, "accounting"); + +insert into emp (emp_id, name, salary, dept_id, mgr) values +(1, "bill", 1000, 10, null), +(20, "john", 500, 10, 1), +(30, "jane", 750, 10,1 ); + +select vtq_commit_ts(max(sys_trx_start)) into @ts_1 from emp; + +update emp set mgr=30 where name ="john"; +select vtq_commit_ts(sys_trx_start) into @ts_2 from emp where name="john"; + +/* All report to 'Bill' */ +with recursive +ancestors +as +( + select e.emp_id, e.name, e.mgr, e.salary + from emp as e for system_time as of timestamp @ts_1 + where name = 'bill' + union + select e.emp_id, e.name, e.mgr, e.salary + from emp as e for system_time as of timestamp @ts_1, + ancestors as a + where e.mgr = a.emp_id +) +select * from ancestors; + +/* Expected 3 rows */ +with recursive +ancestors +as +( + select e.emp_id, e.name, e.mgr, e.salary + from emp as e for system_time as of timestamp @ts_2 + where name = 'bill' + union + select e.emp_id, e.name, e.mgr, e.salary + from emp as e for system_time as of timestamp @ts_2, + ancestors as a + where e.mgr = a.emp_id +) +select * from ancestors for system_time as of timestamp @ts_2; + +drop table emp; +drop table dept; diff --git a/mysql-test/suite/versioning/t/simple.opt b/mysql-test/suite/versioning/t/simple.opt new file mode 100644 index 00000000000..3596fc4d3bd --- /dev/null +++ b/mysql-test/suite/versioning/t/simple.opt @@ -0,0 +1 @@ +--innodb --default-storage-engine=innodb diff --git a/mysql-test/suite/versioning/t/simple.test b/mysql-test/suite/versioning/t/simple.test new file mode 100644 index 00000000000..bb540f05c26 --- /dev/null +++ b/mysql-test/suite/versioning/t/simple.test @@ -0,0 +1,70 @@ +create or replace table dept ( + dept_id int(10) primary key, + name varchar(100) +) +with system versioning; + +create or replace table emp ( + emp_id int(10) primary key, + dept_id int(10), + name varchar(100), + salary int(10), + constraint `dept-emp-fk` + foreign key (dept_id) references dept (dept_id) + on delete cascade + on update restrict +) +with system versioning; + +select now() into @ts_0; + +insert into dept (dept_id, name) values (10, "accounting"); +commit; + +select vtq_commit_ts(sys_trx_start) into @ts_1 from dept where dept_id=10; + +insert into emp (emp_id, name, salary, dept_id) values (1, "bill", 1000, 10); +commit; + +select vtq_commit_ts(sys_trx_start) into @ts_2 from emp where name="bill"; + +select * from emp; + +update emp set salary=2000 where name="bill"; +commit; + +select vtq_commit_ts(sys_trx_start) into @ts_3 from emp where name="bill"; + +select * from emp; +select * from emp for system_time as of timestamp @ts_2; +select * from emp for system_time as of timestamp @ts_3; +select * from emp e, dept d +where d.dept_id = 10 + and d.dept_id = e.dept_id; + +select * from emp e, dept d +where d.dept_id = 10 + and d.dept_id = e.dept_id +query for system_time from timestamp @ts_1 to timestamp @ts_2; + +select * from emp e, dept d +where d.dept_id = 10 + and d.dept_id = e.dept_id +query for system_time as of timestamp @ts_0; + +select * from emp e, dept d +where d.dept_id = 10 + and d.dept_id = e.dept_id +query for system_time as of timestamp @ts_1; + +select * from emp e, dept d +where d.dept_id = 10 + and d.dept_id = e.dept_id +query for system_time as of timestamp @ts_2; + +select * from emp e, dept d +where d.dept_id = 10 + and d.dept_id = e.dept_id +query for system_time as of timestamp @ts_3; + +drop table emp, dept;