Skip to content
Projects
Groups
Snippets
Help
Loading...
Help
Support
Keyboard shortcuts
?
Submit feedback
Contribute to GitLab
Sign in / Register
Toggle navigation
M
MariaDB
Project overview
Project overview
Details
Activity
Releases
Repository
Repository
Files
Commits
Branches
Tags
Contributors
Graph
Compare
Issues
0
Issues
0
List
Boards
Labels
Milestones
Merge Requests
0
Merge Requests
0
CI / CD
CI / CD
Pipelines
Jobs
Schedules
Analytics
Analytics
CI / CD
Repository
Value Stream
Wiki
Wiki
Snippets
Snippets
Members
Members
Collapse sidebar
Close sidebar
Activity
Graph
Create a new issue
Jobs
Commits
Issue Boards
Open sidebar
nexedi
MariaDB
Commits
642525b9
Commit
642525b9
authored
Apr 28, 2017
by
Aleksey Midenkov
Browse files
Options
Browse Files
Download
Email Patches
Plain Diff
Tests: cte_recursive, simple (new plans)
Author: Alvin Richards
parent
b19645ca
Changes
6
Hide whitespace changes
Inline
Side-by-side
Showing
6 changed files
with
280 additions
and
0 deletions
+280
-0
mysql-test/suite/versioning/r/cte_recursive.result
mysql-test/suite/versioning/r/cte_recursive.result
+68
-0
mysql-test/suite/versioning/r/simple.result
mysql-test/suite/versioning/r/simple.result
+71
-0
mysql-test/suite/versioning/t/cte_recursive.opt
mysql-test/suite/versioning/t/cte_recursive.opt
+1
-0
mysql-test/suite/versioning/t/cte_recursive.test
mysql-test/suite/versioning/t/cte_recursive.test
+69
-0
mysql-test/suite/versioning/t/simple.opt
mysql-test/suite/versioning/t/simple.opt
+1
-0
mysql-test/suite/versioning/t/simple.test
mysql-test/suite/versioning/t/simple.test
+70
-0
No files found.
mysql-test/suite/versioning/r/cte_recursive.result
0 → 100644
View file @
642525b9
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;
mysql-test/suite/versioning/r/simple.result
0 → 100644
View file @
642525b9
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;
mysql-test/suite/versioning/t/cte_recursive.opt
0 → 100644
View file @
642525b9
--innodb --default-storage-engine=innodb
mysql-test/suite/versioning/t/cte_recursive.test
0 → 100644
View file @
642525b9
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
;
mysql-test/suite/versioning/t/simple.opt
0 → 100644
View file @
642525b9
--innodb --default-storage-engine=innodb
mysql-test/suite/versioning/t/simple.test
0 → 100644
View file @
642525b9
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
;
Write
Preview
Markdown
is supported
0%
Try again
or
attach a new file
Attach a file
Cancel
You are about to add
0
people
to the discussion. Proceed with caution.
Finish editing this message first!
Cancel
Please
register
or
sign in
to comment