mirror of
				https://github.com/MariaDB/server.git
				synced 2025-10-31 02:46:29 +01:00 
			
		
		
		
	
		
			
				
	
	
		
			249 lines
		
	
	
	
		
			6.2 KiB
		
	
	
	
		
			Text
		
	
	
	
	
	
			
		
		
	
	
			249 lines
		
	
	
	
		
			6.2 KiB
		
	
	
	
		
			Text
		
	
	
	
	
	
| if (`SELECT $PS_PROTOCOL + $CURSOR_PROTOCOL > 0`)
 | |
| {
 | |
|    --skip Test temporarily disabled for ps-protocol and cursor-protocol
 | |
| }
 | |
| --source include/have_innodb.inc
 | |
| --source include/default_optimizer_switch.inc
 | |
| --source include/word_size.inc
 | |
| --source suite/versioning/sys_time.inc
 | |
| 
 | |
| --let $replace_regex_tsltz6= /TIMESTAMP..WITH LOCAL TIME ZONE..'....-..-.. ..:..:..[.]......'/TIMESTAMP\/*WITH LOCAL TIME ZONE*\/'YYYY-MM-DD hh:ss:mm:.uuuuuu'/
 | |
| 
 | |
| SET @saved_stats_persistent = @@GLOBAL.innodb_stats_persistent;
 | |
| SET GLOBAL innodb_stats_persistent = OFF;
 | |
| 
 | |
| set time_zone="+00:00";
 | |
| set default_storage_engine=innodb;
 | |
| 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 );
 | |
| 
 | |
| --disable_cursor_protocol
 | |
| select row_start into @ts_1 from emp where name="jane";
 | |
| --enable_cursor_protocol
 | |
| 
 | |
| update emp set mgr=30 where name ="john";
 | |
| 
 | |
| --replace_regex $replace_regex_tsltz6
 | |
| explain extended
 | |
| with ancestors as (
 | |
|   select e.emp_id, e.name, e.mgr, e.salary from emp as e where name = 'bill'
 | |
|     union
 | |
|   select e.emp_id, e.name, e.mgr, e.salary from emp as e
 | |
| ) select * from ancestors for system_time as of @ts_1;
 | |
| 
 | |
| --disable_cursor_protocol
 | |
| select row_start into @ts_2 from emp where name="john";
 | |
| --enable_cursor_protocol
 | |
| 
 | |
| let $q=
 | |
| /* All report to 'Bill' */
 | |
| with recursive
 | |
| ancestors
 | |
| as
 | |
| (
 | |
|   select e.emp_id, e.name, e.mgr, e.salary
 | |
|   from emp for system_time as of timestamp @ts_1 as e
 | |
|   where name = 'bill'
 | |
|   union
 | |
|   select e.emp_id, e.name, e.mgr, e.salary
 | |
|   from emp for system_time as of timestamp @ts_1 as e,
 | |
|        ancestors as a
 | |
|   where e.mgr = a.emp_id
 | |
| )
 | |
| select * from ancestors;
 | |
| 
 | |
| --replace_regex $replace_regex_tsltz6
 | |
| eval explain extended $q;
 | |
| eval $q;
 | |
| 
 | |
| let $q=with recursive
 | |
| ancestors
 | |
| as
 | |
| (
 | |
|   select e.emp_id, e.name, e.mgr, e.salary
 | |
|   from emp as e
 | |
|   where name = 'bill'
 | |
|   union
 | |
|   select e.emp_id, e.name, e.mgr, e.salary
 | |
|   from emp as e,
 | |
|        ancestors as a
 | |
|   where e.mgr = a.emp_id
 | |
| )
 | |
| select * from ancestors for system_time as of timestamp @ts_1;
 | |
| 
 | |
| --replace_regex $replace_regex_tsltz6
 | |
| eval explain extended $q;
 | |
| eval $q;
 | |
| 
 | |
| let $q=with recursive
 | |
| ancestors
 | |
| as
 | |
| (
 | |
|   select e.emp_id, e.name, e.mgr, e.salary
 | |
|   from emp as e
 | |
|   where name = 'bill'
 | |
|   union
 | |
|   select e.emp_id, e.name, e.mgr, e.salary
 | |
|   from emp as e,
 | |
|        ancestors as a
 | |
|   where e.mgr = a.emp_id
 | |
| )
 | |
| select name from emp where emp_id in (select emp_id from ancestors for system_time as of timestamp @ts_1);
 | |
| 
 | |
| --replace_regex $replace_regex_tsltz6 /$sys_time_max/SYS_TIME_MAX/
 | |
| eval explain extended $q;
 | |
| eval $q;
 | |
| 
 | |
| with recursive
 | |
| ancestors
 | |
| as
 | |
| (
 | |
|   select e.emp_id, e.name, e.mgr, e.salary
 | |
|   from emp as e
 | |
|   where name = 'bill'
 | |
|   union
 | |
|   select e.emp_id, e.name, e.mgr, e.salary
 | |
|   from emp as e,
 | |
|        ancestors as a
 | |
|   where e.mgr = a.emp_id
 | |
| )
 | |
| select * from ancestors for system_time as of @ts_2,
 | |
|               ancestors for system_time as of @ts_2 a2;
 | |
| 
 | |
| --error ER_CONFLICTING_FOR_SYSTEM_TIME
 | |
| with recursive
 | |
| ancestors
 | |
| as
 | |
| (
 | |
|   select e.emp_id, e.name, e.mgr, e.salary
 | |
|   from emp as e
 | |
|   where name = 'bill'
 | |
|   union
 | |
|   select e.emp_id, e.name, e.mgr, e.salary
 | |
|   from emp as e,
 | |
|        ancestors as a
 | |
|   where e.mgr = a.emp_id
 | |
| )
 | |
| select * from ancestors for system_time as of @ts_2,
 | |
|               ancestors for system_time as of now() a2;
 | |
| 
 | |
| --error ER_CONFLICTING_FOR_SYSTEM_TIME
 | |
| with recursive
 | |
| ancestors
 | |
| as
 | |
| (
 | |
|   select e.emp_id, e.name, e.mgr, e.salary
 | |
|   from emp as e
 | |
|   where name = 'bill'
 | |
|   union
 | |
|   select e.emp_id, e.name, e.mgr, e.salary
 | |
|   from emp as e,
 | |
|        ancestors as a
 | |
|   where e.mgr = a.emp_id
 | |
| )
 | |
| select * from ancestors,
 | |
|               ancestors for system_time as of @ts_2 a2;
 | |
| 
 | |
| --error ER_CONFLICTING_FOR_SYSTEM_TIME
 | |
| with recursive
 | |
| ancestors
 | |
| as
 | |
| (
 | |
|   select e.emp_id, e.name, e.mgr, e.salary
 | |
|   from emp as e
 | |
|   where name = 'bill'
 | |
|   union
 | |
|   select e.emp_id, e.name, e.mgr, e.salary
 | |
|   from emp as e,
 | |
|        ancestors as a
 | |
|   where e.mgr = a.emp_id
 | |
| )
 | |
| select * from ancestors for system_time as of @ts_2,
 | |
|               ancestors a2;
 | |
| 
 | |
| --error ER_CONFLICTING_FOR_SYSTEM_TIME
 | |
| with recursive
 | |
| ancestors
 | |
| as
 | |
| (
 | |
|   select e.emp_id, e.name, e.mgr, e.salary
 | |
|   from emp as e
 | |
|   where name = 'bill'
 | |
|   union
 | |
|   select e.emp_id, e.name, e.mgr, e.salary
 | |
|   from emp as e,
 | |
|        ancestors as a
 | |
|   where e.mgr = a.emp_id
 | |
| )
 | |
| select * from ancestors for system_time as of @ts_2
 | |
|  where emp_id in (select * from ancestors);
 | |
| 
 | |
| --echo # SYSTEM_TIME to internal recursive instance is prohibited
 | |
| --error ER_VERS_NOT_VERSIONED
 | |
| with recursive cte as
 | |
| (
 | |
|   select * from emp
 | |
|   union all
 | |
|   select * from cte for system_time as of @ts_1
 | |
| )
 | |
| select * from cte;
 | |
| 
 | |
| create or replace table emp ( emp_id int, name varchar(127), mgr int) with system versioning;
 | |
| create or replace table addr ( emp_id int, address varchar(100)) with system versioning;
 | |
| insert emp values (1, 'bill', 0), (2, 'bill', 1), (3, 'kate', 1);
 | |
| insert addr values (1, 'Moscow'), (2, 'New York'), (3, 'London');
 | |
| set @ts=now(6);
 | |
| delete from emp;
 | |
| delete from addr;
 | |
| 
 | |
| with recursive
 | |
| ancestors
 | |
| as
 | |
| (
 | |
|   select e.emp_id, e.name, e.mgr
 | |
|   from emp for system_time as of timestamp @ts as e
 | |
|   where name = 'bill'
 | |
|   union
 | |
|   select ee.emp_id, ee.name, ee.mgr
 | |
|   from emp for system_time as of timestamp @ts as ee, ancestors as a
 | |
|   where ee.mgr = a.emp_id
 | |
| )
 | |
| select * from ancestors;
 | |
| 
 | |
| insert emp values (4, 'john', 1);
 | |
| insert addr values (4, 'Paris');
 | |
| with ancestors as (select * from emp natural join addr) select * from ancestors;
 | |
| with ancestors as (select * from emp natural join addr) select * from ancestors for system_time all;
 | |
| with ancestors as (select * from (select * from emp natural join addr) for system_time all as t) select * from ancestors;
 | |
| select * from (select * from emp natural join addr) for system_time all as t;
 | |
| 
 | |
| drop table emp;
 | |
| drop table dept;
 | |
| drop table addr;
 | |
| 
 | |
| SET GLOBAL innodb_stats_persistent = @saved_stats_persistent;
 | 
