mirror of
https://github.com/MariaDB/server.git
synced 2025-01-17 20:42:30 +01:00
de15763cfb
into mysql.com:/home/svoj/devel/mysql/BUG24342/mysql-5.0-engines myisam/mi_rkey.c: Auto merged myisam/myisamdef.h: Auto merged myisammrg/myrg_rkey.c: Auto merged mysql-test/t/merge.test: Auto merged mysql-test/r/merge.result: SCCS merged
489 lines
15 KiB
Text
489 lines
15 KiB
Text
#
|
|
# test of MERGE TABLES
|
|
#
|
|
|
|
--disable_warnings
|
|
drop table if exists t1,t2,t3,t4,t5,t6;
|
|
drop database if exists mysqltest;
|
|
--enable_warnings
|
|
|
|
create table t1 (a int not null primary key auto_increment, message char(20));
|
|
create table t2 (a int not null primary key auto_increment, message char(20));
|
|
INSERT INTO t1 (message) VALUES ("Testing"),("table"),("t1");
|
|
INSERT INTO t2 (message) VALUES ("Testing"),("table"),("t2");
|
|
create table t3 (a int not null, b char(20), key(a)) engine=MERGE UNION=(t1,t2);
|
|
select * from t3;
|
|
select * from t3 order by a desc;
|
|
drop table t3;
|
|
insert into t1 select NULL,message from t2;
|
|
insert into t2 select NULL,message from t1;
|
|
insert into t1 select NULL,message from t2;
|
|
insert into t2 select NULL,message from t1;
|
|
insert into t1 select NULL,message from t2;
|
|
insert into t2 select NULL,message from t1;
|
|
insert into t1 select NULL,message from t2;
|
|
insert into t2 select NULL,message from t1;
|
|
insert into t1 select NULL,message from t2;
|
|
insert into t2 select NULL,message from t1;
|
|
insert into t1 select NULL,message from t2;
|
|
create table t3 (a int not null, b char(20), key(a)) engine=MERGE UNION=(test.t1,test.t2);
|
|
explain select * from t3 where a < 10;
|
|
explain select * from t3 where a > 10 and a < 20;
|
|
select * from t3 where a = 10;
|
|
select * from t3 where a < 10;
|
|
select * from t3 where a > 10 and a < 20;
|
|
explain select a from t3 order by a desc limit 10;
|
|
select a from t3 order by a desc limit 10;
|
|
select a from t3 order by a desc limit 300,10;
|
|
delete from t3 where a=3;
|
|
select * from t3 where a < 10;
|
|
delete from t3 where a >= 6 and a <= 8;
|
|
select * from t3 where a < 10;
|
|
update t3 set a=3 where a=9;
|
|
select * from t3 where a < 10;
|
|
update t3 set a=6 where a=7;
|
|
select * from t3 where a < 10;
|
|
show create table t3;
|
|
|
|
# The following should give errors
|
|
create table t4 (a int not null, b char(10), key(a)) engine=MERGE UNION=(t1,t2);
|
|
--error 1168
|
|
select * from t4;
|
|
--error 1168
|
|
alter table t4 add column c int;
|
|
|
|
#
|
|
# Test tables in different databases
|
|
#
|
|
create database mysqltest;
|
|
create table mysqltest.t6 (a int not null primary key auto_increment, message char(20));
|
|
create table t5 (a int not null, b char(20), key(a)) engine=MERGE UNION=(test.t1,mysqltest.t6);
|
|
show create table t5;
|
|
alter table t5 engine=myisam;
|
|
drop table t5, mysqltest.t6;
|
|
drop database mysqltest;
|
|
|
|
# Because of windows, it's important that we drop the merge tables first!
|
|
drop table t4,t3,t1,t2;
|
|
|
|
create table t1 (c char(10)) engine=myisam;
|
|
create table t2 (c char(10)) engine=myisam;
|
|
create table t3 (c char(10)) union=(t1,t2) engine=merge;
|
|
insert into t1 (c) values ('test1');
|
|
insert into t1 (c) values ('test1');
|
|
insert into t1 (c) values ('test1');
|
|
insert into t2 (c) values ('test2');
|
|
insert into t2 (c) values ('test2');
|
|
insert into t2 (c) values ('test2');
|
|
select * from t3;
|
|
select * from t3;
|
|
delete from t3 where 1=1;
|
|
select * from t3;
|
|
select * from t1;
|
|
drop table t3,t2,t1;
|
|
|
|
#
|
|
# Test 2
|
|
#
|
|
|
|
CREATE TABLE t1 (incr int not null, othr int not null, primary key(incr));
|
|
CREATE TABLE t2 (incr int not null, othr int not null, primary key(incr));
|
|
CREATE TABLE t3 (incr int not null, othr int not null, primary key(incr))
|
|
ENGINE=MERGE UNION=(t1,t2);
|
|
|
|
SELECT * from t3;
|
|
|
|
INSERT INTO t1 VALUES ( 1,10),( 3,53),( 5,21),( 7,12),( 9,17);
|
|
INSERT INTO t2 VALUES ( 2,24),( 4,33),( 6,41),( 8,26),( 0,32);
|
|
INSERT INTO t1 VALUES (11,20),(13,43),(15,11),(17,22),(19,37);
|
|
INSERT INTO t2 VALUES (12,25),(14,31),(16,42),(18,27),(10,30);
|
|
|
|
SELECT * from t3 where incr in (1,2,3,4) order by othr;
|
|
alter table t3 UNION=(t1);
|
|
select count(*) from t3;
|
|
alter table t3 UNION=(t1,t2);
|
|
select count(*) from t3;
|
|
alter table t3 ENGINE=MYISAM;
|
|
select count(*) from t3;
|
|
|
|
# Test that ALTER TABLE rembers the old UNION
|
|
|
|
drop table t3;
|
|
CREATE TABLE t3 (incr int not null, othr int not null, primary key(incr))
|
|
ENGINE=MERGE UNION=(t1,t2);
|
|
show create table t3;
|
|
alter table t3 drop primary key;
|
|
show create table t3;
|
|
|
|
drop table t3,t2,t1;
|
|
|
|
#
|
|
# Test table without unions
|
|
#
|
|
create table t1 (a int not null, key(a)) engine=merge;
|
|
select * from t1;
|
|
drop table t1;
|
|
|
|
#
|
|
# Bug in flush tables combined with MERGE tables
|
|
#
|
|
|
|
create table t1 (a int not null, b int not null, key(a,b));
|
|
create table t2 (a int not null, b int not null, key(a,b));
|
|
create table t3 (a int not null, b int not null, key(a,b)) ENGINE=MERGE UNION=(t1,t2);
|
|
insert into t1 values (1,2),(2,1),(0,0),(4,4),(5,5),(6,6);
|
|
insert into t2 values (1,1),(2,2),(0,0),(4,4),(5,5),(6,6);
|
|
flush tables;
|
|
select * from t3 where a=1 order by b limit 2;
|
|
drop table t3,t1,t2;
|
|
|
|
#
|
|
# [phi] testing INSERT_METHOD stuff
|
|
#
|
|
|
|
# first testing of common stuff with new parameters
|
|
create table t1 (a int not null, b int not null auto_increment, primary key(a,b));
|
|
create table t2 (a int not null, b int not null auto_increment, primary key(a,b));
|
|
create table t3 (a int not null, b int not null, key(a,b)) UNION=(t1,t2) INSERT_METHOD=NO;
|
|
create table t4 (a int not null, b int not null, key(a,b)) ENGINE=MERGE UNION=(t1,t2) INSERT_METHOD=NO;
|
|
create table t5 (a int not null, b int not null auto_increment, primary key(a,b)) ENGINE=MERGE UNION=(t1,t2) INSERT_METHOD=FIRST;
|
|
create table t6 (a int not null, b int not null auto_increment, primary key(a,b)) ENGINE=MERGE UNION=(t1,t2) INSERT_METHOD=LAST;
|
|
show create table t3;
|
|
show create table t4;
|
|
show create table t5;
|
|
show create table t6;
|
|
insert into t1 values (1,NULL),(1,NULL),(1,NULL),(1,NULL);
|
|
insert into t2 values (2,NULL),(2,NULL),(2,NULL),(2,NULL);
|
|
select * from t3 order by b,a limit 3;
|
|
select * from t4 order by b,a limit 3;
|
|
select * from t5 order by b,a limit 3,3;
|
|
select * from t6 order by b,a limit 6,3;
|
|
# now testing inserts and where the data gets written
|
|
insert into t5 values (5,1),(5,2);
|
|
insert into t6 values (6,1),(6,2);
|
|
select * from t1 order by a,b;
|
|
select * from t2 order by a,b;
|
|
select * from t4 order by a,b;
|
|
# preperation for next test
|
|
insert into t3 values (3,1),(3,2),(3,3),(3,4);
|
|
select * from t3 order by a,b;
|
|
# now testing whether options are kept by alter table
|
|
alter table t4 UNION=(t1,t2,t3);
|
|
show create table t4;
|
|
select * from t4 order by a,b;
|
|
# testing switching off insert method and inserts again
|
|
alter table t4 INSERT_METHOD=FIRST;
|
|
show create table t4;
|
|
insert into t4 values (4,1),(4,2);
|
|
select * from t1 order by a,b;
|
|
select * from t2 order by a,b;
|
|
select * from t3 order by a,b;
|
|
select * from t4 order by a,b;
|
|
select * from t5 order by a,b;
|
|
# auto_increment
|
|
select 1;
|
|
insert into t5 values (1,NULL),(5,NULL);
|
|
insert into t6 values (2,NULL),(6,NULL);
|
|
select * from t1 order by a,b;
|
|
select * from t2 order by a,b;
|
|
select * from t5 order by a,b;
|
|
select * from t6 order by a,b;
|
|
insert into t1 values (99,NULL);
|
|
select * from t4 where a+0 > 90;
|
|
# bug#4008 - cannot determine a unique key that caused "dupl. key error"
|
|
--error 1062
|
|
insert t5 values (1,1);
|
|
--error 1062
|
|
insert t6 values (2,1);
|
|
insert t5 values (1,1) on duplicate key update b=b+10;
|
|
insert t6 values (2,1) on duplicate key update b=b+20;
|
|
select * from t5 where a < 3;
|
|
drop table t6, t5, t4, t3, t2, t1;
|
|
|
|
CREATE TABLE t1 ( a int(11) NOT NULL default '0', b int(11) NOT NULL default '0', PRIMARY KEY (a,b)) ENGINE=MyISAM;
|
|
INSERT INTO t1 VALUES (1,1), (2,1);
|
|
CREATE TABLE t2 ( a int(11) NOT NULL default '0', b int(11) NOT NULL default '0', PRIMARY KEY (a,b)) ENGINE=MyISAM;
|
|
INSERT INTO t2 VALUES (1,2), (2,2);
|
|
CREATE TABLE t3 ( a int(11) NOT NULL default '0', b int(11) NOT NULL default '0', KEY a (a,b)) ENGINE=MRG_MyISAM UNION=(t1,t2);
|
|
select max(b) from t3 where a = 2;
|
|
select max(b) from t1 where a = 2;
|
|
drop table t3,t1,t2;
|
|
|
|
#
|
|
# temporary merge tables
|
|
#
|
|
create table t1 (a int not null);
|
|
create table t2 (a int not null);
|
|
insert into t1 values (1);
|
|
insert into t2 values (2);
|
|
create temporary table t3 (a int not null) ENGINE=MERGE UNION=(t1,t2);
|
|
select * from t3;
|
|
create temporary table t4 (a int not null);
|
|
create temporary table t5 (a int not null);
|
|
insert into t4 values (1);
|
|
insert into t5 values (2);
|
|
create temporary table t6 (a int not null) ENGINE=MERGE UNION=(t4,t5);
|
|
select * from t6;
|
|
drop table t6, t3, t1, t2, t4, t5;
|
|
|
|
#
|
|
# testing merge::records_in_range and optimizer
|
|
#
|
|
|
|
CREATE TABLE t1 (
|
|
fileset_id tinyint(3) unsigned NOT NULL default '0',
|
|
file_code varchar(32) NOT NULL default '',
|
|
fileset_root_id tinyint(3) unsigned NOT NULL default '0',
|
|
PRIMARY KEY (fileset_id,file_code),
|
|
KEY files (fileset_id,fileset_root_id)
|
|
) ENGINE=MyISAM;
|
|
INSERT INTO t1 VALUES (2, '0000000111', 1), (2, '0000000112', 1), (2, '0000000113', 1),
|
|
(2, '0000000114', 1), (2, '0000000115', 1), (2, '0000000116', 1), (2, '0000000117', 1),
|
|
(2, '0000000118', 1), (2, '0000000119', 1), (2, '0000000120', 1);
|
|
CREATE TABLE t2 (
|
|
fileset_id tinyint(3) unsigned NOT NULL default '0',
|
|
file_code varchar(32) NOT NULL default '',
|
|
fileset_root_id tinyint(3) unsigned NOT NULL default '0',
|
|
PRIMARY KEY (fileset_id,file_code),
|
|
KEY files (fileset_id,fileset_root_id)
|
|
) ENGINE=MRG_MyISAM UNION=(t1);
|
|
|
|
EXPLAIN SELECT * FROM t2 IGNORE INDEX (files) WHERE fileset_id = 2
|
|
AND file_code BETWEEN '0000000115' AND '0000000120' LIMIT 1;
|
|
EXPLAIN SELECT * FROM t2 WHERE fileset_id = 2
|
|
AND file_code BETWEEN '0000000115' AND '0000000120' LIMIT 1;
|
|
EXPLAIN SELECT * FROM t1 WHERE fileset_id = 2
|
|
AND file_code BETWEEN '0000000115' AND '0000000120' LIMIT 1;
|
|
EXPLAIN SELECT * FROM t2 WHERE fileset_id = 2
|
|
AND file_code = '0000000115' LIMIT 1;
|
|
DROP TABLE t2, t1;
|
|
|
|
#
|
|
# Test of ORDER BY DESC on key (Bug #515)
|
|
#
|
|
|
|
create table t1 (x int, y int, index xy(x, y));
|
|
create table t2 (x int, y int, index xy(x, y));
|
|
create table t3 (x int, y int, index xy(x, y)) engine=merge union=(t1,t2);
|
|
insert into t1 values(1, 2);
|
|
insert into t2 values(1, 3);
|
|
select * from t3 where x = 1 and y < 5 order by y;
|
|
# Bug is that followng query returns empty set while it must be same as above
|
|
select * from t3 where x = 1 and y < 5 order by y desc;
|
|
drop table t1,t2,t3;
|
|
|
|
#
|
|
# Bug#5232: CREATE TABLE ... SELECT
|
|
#
|
|
|
|
create table t1 (a int);
|
|
create table t2 (a int);
|
|
insert into t1 values (0);
|
|
insert into t2 values (1);
|
|
--error 1093
|
|
create table t3 engine=merge union=(t1, t2) select * from t1;
|
|
--error 1093
|
|
create table t3 engine=merge union=(t1, t2) select * from t2;
|
|
--error 1093
|
|
create table t3 engine=merge union=(t1, t2) select (select max(a) from t2);
|
|
drop table t1, t2;
|
|
|
|
#
|
|
# Bug#9112 - Merge table with composite index producing invalid results with some queries
|
|
# This test case will fail only without the bugfix and some
|
|
# non-deterministic circumstances. It depends on properly initialized
|
|
# "un-initialized" memory. At the time it happens with a standard
|
|
# non-debug build. But there is no guarantee that this will be always so.
|
|
#
|
|
create table t1 (
|
|
a double(14,4),
|
|
b varchar(10),
|
|
index (a,b)
|
|
) engine=merge union=(t2,t3);
|
|
|
|
create table t2 (
|
|
a double(14,4),
|
|
b varchar(10),
|
|
index (a,b)
|
|
) engine=myisam;
|
|
|
|
create table t3 (
|
|
a double(14,4),
|
|
b varchar(10),
|
|
index (a,b)
|
|
) engine=myisam;
|
|
|
|
insert into t2 values ( null, '');
|
|
insert into t2 values ( 9999999999.999, '');
|
|
insert into t3 select * from t2;
|
|
select min(a), max(a) from t1;
|
|
flush tables;
|
|
select min(a), max(a) from t1;
|
|
drop table t1, t2, t3;
|
|
# BUG#6699 : no sorting on 'ref' retrieval
|
|
create table t1 (a int,b int,c int, index (a,b,c));
|
|
create table t2 (a int,b int,c int, index (a,b,c));
|
|
create table t3 (a int,b int,c int, index (a,b,c))
|
|
engine=merge union=(t1 ,t2);
|
|
insert into t1 (a,b,c) values (1,1,0),(1,2,0);
|
|
insert into t2 (a,b,c) values (1,1,1),(1,2,1);
|
|
|
|
explain select a,b,c from t3 force index (a) where a=1 order by a,b,c;
|
|
select a,b,c from t3 force index (a) where a=1 order by a,b,c;
|
|
|
|
# this actually wasn't affected:
|
|
explain select a,b,c from t3 force index (a) where a=1 order by a desc, b desc, c desc;
|
|
select a,b,c from t3 force index (a) where a=1 order by a desc, b desc, c desc;
|
|
|
|
# BUG#7377 SHOW index on MERGE table crashes debug server
|
|
show index from t3;
|
|
|
|
drop table t1, t2, t3;
|
|
|
|
#
|
|
# Bug#10400 - Improperly-defined MERGE table crashes with INSERT ... ON DUPLICATE KEY UPDATE
|
|
#
|
|
CREATE TABLE t1 ( a INT AUTO_INCREMENT PRIMARY KEY, b VARCHAR(10), UNIQUE (b) )
|
|
ENGINE=MyISAM;
|
|
CREATE TABLE t2 ( a INT AUTO_INCREMENT, b VARCHAR(10), INDEX (a), INDEX (b) )
|
|
ENGINE=MERGE UNION (t1) INSERT_METHOD=FIRST;
|
|
INSERT INTO t2 (b) VALUES (1) ON DUPLICATE KEY UPDATE b=2;
|
|
INSERT INTO t2 (b) VALUES (1) ON DUPLICATE KEY UPDATE b=3;
|
|
SELECT b FROM t2;
|
|
DROP TABLE t1, t2;
|
|
|
|
|
|
#
|
|
# BUG#5390 - problems with merge tables
|
|
# Problem #1: INSERT...SELECT
|
|
#
|
|
#drop table if exists t1, t2, t3;
|
|
create table t1(a int);
|
|
create table t2(a int);
|
|
insert into t1 values (1);
|
|
insert into t2 values (2);
|
|
create table t3 (a int) engine=merge union=(t1, t2) insert_method=first;
|
|
select * from t3;
|
|
#
|
|
insert t2 select * from t2;
|
|
select * from t2;
|
|
#
|
|
insert t3 select * from t1;
|
|
select * from t3;
|
|
#
|
|
insert t1 select * from t3;
|
|
select * from t1;
|
|
select * from t2;
|
|
select * from t3;
|
|
check table t1, t2;
|
|
drop table t1, t2, t3;
|
|
|
|
#
|
|
# BUG#21617 - crash when selecting from merge table with inconsistent
|
|
# indexes
|
|
#
|
|
CREATE TABLE t1(a INT);
|
|
INSERT INTO t1 VALUES(2),(1);
|
|
CREATE TABLE t2(a INT, KEY(a)) ENGINE=MERGE UNION=(t1);
|
|
--error 1168
|
|
SELECT * FROM t2 WHERE a=2;
|
|
DROP TABLE t1, t2;
|
|
|
|
#
|
|
# BUG#10974 - No error message if merge table based on union of innodb,
|
|
# memory
|
|
#
|
|
CREATE TABLE t1(a INT) ENGINE=MEMORY;
|
|
CREATE TABLE t2(a INT) ENGINE=MERGE UNION=(t1);
|
|
--error 1168
|
|
SELECT * FROM t2;
|
|
DROP TABLE t1, t2;
|
|
CREATE TABLE t2(a INT) ENGINE=MERGE UNION=(t3);
|
|
--error 1168
|
|
SELECT * FROM t2;
|
|
DROP TABLE t2;
|
|
|
|
#
|
|
# Underlying table definition conformance tests.
|
|
#
|
|
CREATE TABLE t1(a INT, b TEXT);
|
|
CREATE TABLE tm1(a TEXT, b INT) ENGINE=MERGE UNION=(t1);
|
|
--error 1168
|
|
SELECT * FROM tm1;
|
|
DROP TABLE t1, tm1;
|
|
|
|
CREATE TABLE t1(a SMALLINT, b SMALLINT);
|
|
CREATE TABLE tm1(a INT) ENGINE=MERGE UNION=(t1);
|
|
--error 1168
|
|
SELECT * FROM tm1;
|
|
DROP TABLE t1, tm1;
|
|
|
|
CREATE TABLE t1(a SMALLINT, b SMALLINT, KEY(a, b));
|
|
CREATE TABLE tm1(a SMALLINT, b SMALLINT, KEY(a)) ENGINE=MERGE UNION=(t1);
|
|
--error 1168
|
|
SELECT * FROM tm1;
|
|
DROP TABLE t1, tm1;
|
|
|
|
CREATE TABLE t1(a SMALLINT, b SMALLINT, KEY(b));
|
|
CREATE TABLE tm1(a SMALLINT, b SMALLINT, KEY(a)) ENGINE=MERGE UNION=(t1);
|
|
--error 1168
|
|
SELECT * FROM tm1;
|
|
DROP TABLE t1, tm1;
|
|
|
|
|
|
# BUG#26881 - Large MERGE tables report incorrect specification when no
|
|
# differences in tables
|
|
#
|
|
CREATE TABLE t1(c1 VARCHAR(1));
|
|
CREATE TABLE m1 LIKE t1;
|
|
ALTER TABLE m1 ENGINE=MERGE UNION=(t1);
|
|
SELECT * FROM m1;
|
|
DROP TABLE t1, m1;
|
|
|
|
CREATE TABLE t1(c1 VARCHAR(4), c2 TINYINT, c3 TINYINT, c4 TINYINT,
|
|
c5 TINYINT, c6 TINYINT, c7 TINYINT, c8 TINYINT, c9 TINYINT);
|
|
CREATE TABLE m1 LIKE t1;
|
|
ALTER TABLE m1 ENGINE=MERGE UNION=(t1);
|
|
SELECT * FROM m1;
|
|
DROP TABLE t1, m1;
|
|
|
|
#
|
|
# BUG#24342 - Incorrect results with query over MERGE table
|
|
#
|
|
CREATE TABLE t1 (a VARCHAR(255) CHARACTER SET latin1 COLLATE latin1_german2_ci,
|
|
b INT, INDEX(a,b));
|
|
CREATE TABLE t2 LIKE t1;
|
|
CREATE TABLE t3 LIKE t1;
|
|
ALTER TABLE t3 ENGINE=MERGE UNION=(t1,t2);
|
|
INSERT INTO t1 VALUES ('ss',1);
|
|
INSERT INTO t2 VALUES ('ss',2),(0xDF,2);
|
|
SELECT COUNT(*) FROM t3 WHERE a=0xDF AND b=2;
|
|
DROP TABLE t1,t2,t3;
|
|
|
|
# End of 4.1 tests
|
|
|
|
#
|
|
# BUG#19648 - Merge table does not work with bit types
|
|
#
|
|
create table t1 (b bit(1));
|
|
create table t2 (b bit(1));
|
|
create table tm (b bit(1)) engine = merge union = (t1,t2);
|
|
select * from tm;
|
|
drop table tm, t1, t2;
|
|
|
|
#
|
|
# Bug #17766: The server accepts to create MERGE tables which cannot work
|
|
#
|
|
create table t1 (a int) insert_method = last engine = merge;
|
|
--error ER_OPEN_AS_READONLY
|
|
insert into t1 values (1);
|
|
create table t2 (a int) engine = myisam;
|
|
alter table t1 union (t2);
|
|
insert into t1 values (1);
|
|
alter table t1 insert_method = no;
|
|
--error ER_OPEN_AS_READONLY
|
|
insert into t1 values (1);
|
|
drop table t2;
|
|
drop table t1;
|
|
|
|
--echo End of 5.0 tests
|