mirror of
https://github.com/MariaDB/server.git
synced 2025-01-16 03:52:35 +01:00
9e1fb104a3
-----BEGIN PGP SIGNATURE----- iQIzBAABCgAdFiEEF39AEP5WyjM2MAMF8WVvJMdM0dgFAmck77AACgkQ8WVvJMdM 0dgccQ/+Lls8fWt4D+gMPP7x+drJSO/IE/gZFt3ugbWF+/p3B2xXAs5AAE83wxEh QSbp4DCkb/9PnuakhLmzg0lFbxMUlh4rsJ1YyiuLB2J+YgKbAc36eQQf+rtYSipd DT5uRk36c9wOcOXo/mMv4APEvpPXBIBdIL4VvpKFbIOE7xT24Sp767zWXdXqrB1f JgOQdM2ct+bvSPC55oZ5p1kqyxwvd6K6+3RB3CIpwW9zrVSLg7enT3maLjj/761s jvlRae+Cv+r+Hit9XpmEH6n2FYVgIJ3o3WhdAHwN0kxKabXYTg7OCB7QxDZiUHI9 C/5goKmKaPB1PCQyuTQyLSyyK9a8nPfgn6tqw/p/ZKDQhKT9sWJv/5bSWecrVndx LLYifSTrFC/eXLzgPvCnNv/U8SjsZaAdMIKS681+qDJ0P5abghUIlGnMYTjYXuX1 1B6Vrr0bdrQ3V1CLB3tpkRjpUvicrsabtuAUAP65QnEG2G9UJXklOer+DE291Gsl f1I0o6C1zVGAOkUUD3QEYaHD8w7hlvyfKme5oXKUm3DOjaAar5UUKLdr6prxRZL4 ebhmGEy42Mf8fBYoeohIxmxgvv6h2Xd9xCukgPp8hFpqJGw8abg7JNZTTKH4h2IY J51RpD10h4eoi6WRn3opEcjexTGvZ+xNR7yYO5WxWw6VIre9IUA= =s+WW -----END PGP SIGNATURE----- Merge tag '11.4' into 11.6 MariaDB 11.4.4 release
746 lines
18 KiB
Text
746 lines
18 KiB
Text
#
|
|
# Check for problems with delete
|
|
#
|
|
|
|
call mtr.add_suppression("Sort aborted.*");
|
|
|
|
--disable_warnings
|
|
drop table if exists t1,t2,t3,t11,t12;
|
|
--enable_warnings
|
|
CREATE TABLE t1 (a tinyint(3), b tinyint(5));
|
|
INSERT INTO t1 VALUES (1,1);
|
|
INSERT LOW_PRIORITY INTO t1 VALUES (1,2);
|
|
INSERT INTO t1 VALUES (1,3);
|
|
DELETE from t1 where a=1 limit 1;
|
|
DELETE LOW_PRIORITY from t1 where a=1;
|
|
|
|
INSERT INTO t1 VALUES (1,1);
|
|
DELETE from t1;
|
|
LOCK TABLE t1 write;
|
|
INSERT INTO t1 VALUES (1,2);
|
|
DELETE from t1;
|
|
UNLOCK TABLES;
|
|
INSERT INTO t1 VALUES (1,2);
|
|
SET AUTOCOMMIT=0;
|
|
DELETE from t1;
|
|
SET AUTOCOMMIT=1;
|
|
drop table t1;
|
|
|
|
#
|
|
# Test of delete when the delete will cause a node to disappear and reappear
|
|
# (This assumes a block size of 1024)
|
|
#
|
|
|
|
create table t1 (
|
|
a bigint not null,
|
|
b bigint not null default 0,
|
|
c bigint not null default 0,
|
|
d bigint not null default 0,
|
|
e bigint not null default 0,
|
|
f bigint not null default 0,
|
|
g bigint not null default 0,
|
|
h bigint not null default 0,
|
|
i bigint not null default 0,
|
|
j bigint not null default 0,
|
|
primary key (a,b,c,d,e,f,g,h,i,j));
|
|
insert into t1 (a) values (2),(4),(6),(8),(10),(12),(14),(16),(18),(20),(22),(24),(26),(23);
|
|
delete from t1 where a=26;
|
|
drop table t1;
|
|
create table t1 (
|
|
a bigint not null,
|
|
b bigint not null default 0,
|
|
c bigint not null default 0,
|
|
d bigint not null default 0,
|
|
e bigint not null default 0,
|
|
f bigint not null default 0,
|
|
g bigint not null default 0,
|
|
h bigint not null default 0,
|
|
i bigint not null default 0,
|
|
j bigint not null default 0,
|
|
primary key (a,b,c,d,e,f,g,h,i,j));
|
|
insert into t1 (a) values (2),(4),(6),(8),(10),(12),(14),(16),(18),(20),(22),(24),(26),(23),(27);
|
|
delete from t1 where a=27;
|
|
drop table t1;
|
|
|
|
CREATE TABLE `t1` (
|
|
`i` int(10) NOT NULL default '0',
|
|
`i2` int(10) NOT NULL default '0',
|
|
PRIMARY KEY (`i`)
|
|
);
|
|
-- error 1054
|
|
DELETE FROM t1 USING t1 WHERE post='1';
|
|
drop table t1;
|
|
|
|
#
|
|
# CHAR(0) bug - not actually DELETE bug, but anyway...
|
|
#
|
|
|
|
CREATE TABLE t1 (
|
|
bool char(0) default NULL,
|
|
not_null varchar(20) binary NOT NULL default '',
|
|
misc integer not null,
|
|
PRIMARY KEY (not_null)
|
|
) ENGINE=MyISAM;
|
|
|
|
INSERT INTO t1 VALUES (NULL,'a',4), (NULL,'b',5), (NULL,'c',6), (NULL,'d',7);
|
|
|
|
select * from t1 where misc > 5 and bool is null;
|
|
delete from t1 where misc > 5 and bool is null;
|
|
select * from t1 where misc > 5 and bool is null;
|
|
|
|
select count(*) from t1;
|
|
delete from t1 where 1 > 2;
|
|
select count(*) from t1;
|
|
delete from t1 where 3 > 2;
|
|
select count(*) from t1;
|
|
|
|
drop table t1;
|
|
#
|
|
# Bug #5733: Table handler error with self-join multi-table DELETE
|
|
#
|
|
|
|
create table t1 (a int not null auto_increment primary key, b char(32));
|
|
insert into t1 (b) values ('apple'), ('apple');
|
|
select * from t1;
|
|
delete t1 from t1, t1 as t2 where t1.b = t2.b and t1.a > t2.a;
|
|
select * from t1;
|
|
drop table t1;
|
|
|
|
--echo #
|
|
--echo # IGNORE option
|
|
--echo #
|
|
create table t11 (a int NOT NULL, b int, primary key (a));
|
|
create table t12 (a int NOT NULL, b int, primary key (a));
|
|
create table t2 (a int NOT NULL, b int, primary key (a));
|
|
insert into t11 values (0, 10),(1, 11),(2, 12);
|
|
insert into t12 values (33, 10),(0, 11),(2, 12);
|
|
insert into t2 values (1, 21),(2, 12),(3, 23);
|
|
select * from t11;
|
|
select * from t12;
|
|
select * from t2;
|
|
-- error 1242
|
|
delete t11.*, t12.* from t11,t12 where t11.a = t12.a and t11.b <> (select b from t2 where t11.a < t2.a);
|
|
select * from t11;
|
|
select * from t12;
|
|
explain delete ignore t11.*, t12.* from t11,t12 where t11.a = t12.a and t11.b <> (select b from t2 where t11.a < t2.a);
|
|
delete ignore t11.*, t12.* from t11,t12 where t11.a = t12.a and t11.b <> (select b from t2 where t11.a < t2.a);
|
|
select * from t11;
|
|
select * from t12;
|
|
insert into t11 values (2, 12);
|
|
-- error 1242
|
|
delete from t11 where t11.b <> (select b from t2 where t11.a < t2.a);
|
|
select * from t11;
|
|
delete ignore from t11 where t11.b <> (select b from t2 where t11.a < t2.a);
|
|
select * from t11;
|
|
drop table t11, t12, t2;
|
|
|
|
#
|
|
# Bug #4198: deletion and KEYREAD
|
|
#
|
|
|
|
create table t1 (a int, b int, unique key (a), key (b));
|
|
insert into t1 values (3, 3), (7, 7);
|
|
delete t1 from t1 where a = 3;
|
|
check table t1;
|
|
select * from t1;
|
|
drop table t1;
|
|
|
|
#
|
|
# Bug #8392: delete with ORDER BY containing a direct reference to the table
|
|
#
|
|
|
|
CREATE TABLE t1 ( a int PRIMARY KEY );
|
|
DELETE FROM t1 WHERE t1.a > 0 ORDER BY t1.a;
|
|
INSERT INTO t1 VALUES (0),(1),(2);
|
|
DELETE FROM t1 WHERE t1.a > 0 ORDER BY t1.a LIMIT 1;
|
|
SELECT * FROM t1;
|
|
DROP TABLE t1;
|
|
|
|
#
|
|
# Bug #21392: multi-table delete with alias table name fails with
|
|
# 1003: Incorrect table name
|
|
#
|
|
|
|
create table t1 (a int);
|
|
delete `4.t1` from t1 as `4.t1` where `4.t1`.a = 5;
|
|
delete FROM `4.t1` USING t1 as `4.t1` where `4.t1`.a = 5;
|
|
drop table t1;
|
|
|
|
#
|
|
# Bug#17711: DELETE doesn't use index when ORDER BY, LIMIT and
|
|
# non-restricting WHERE is present.
|
|
#
|
|
create table t1(f1 int primary key);
|
|
insert into t1 values (4),(3),(1),(2);
|
|
delete from t1 where (@a:= f1) order by f1 limit 1;
|
|
select @a;
|
|
drop table t1;
|
|
|
|
# BUG#30385 "Server crash when deleting with order by and limit"
|
|
CREATE TABLE t1 (
|
|
`date` date ,
|
|
`time` time ,
|
|
`seq` int(10) unsigned NOT NULL auto_increment,
|
|
PRIMARY KEY (`seq`),
|
|
KEY `seq` (`seq`),
|
|
KEY `time` (`time`),
|
|
KEY `date` (`date`)
|
|
);
|
|
DELETE FROM t1 ORDER BY date ASC, time ASC LIMIT 1;
|
|
drop table t1;
|
|
|
|
--echo End of 4.1 tests
|
|
|
|
#
|
|
# Test of multi-delete where we are not scanning the first table
|
|
#
|
|
|
|
CREATE TABLE t1 (a int not null,b int not null);
|
|
CREATE TABLE t2 (a int not null, b int not null, primary key (a,b));
|
|
CREATE TABLE t3 (a int not null, b int not null, primary key (a,b));
|
|
insert into t1 values (1,1),(2,1),(1,3);
|
|
insert into t2 values (1,1),(2,2),(3,3);
|
|
insert into t3 values (1,1),(2,1),(1,3);
|
|
select * from t1,t2,t3 where t1.a=t2.a AND t2.b=t3.a and t1.b=t3.b;
|
|
explain select * from t1,t2,t3 where t1.a=t2.a AND t2.b=t3.a and t1.b=t3.b;
|
|
delete t2.*,t3.* from t1,t2,t3 where t1.a=t2.a AND t2.b=t3.a and t1.b=t3.b;
|
|
# This should be empty
|
|
select * from t3;
|
|
drop table t1,t2,t3;
|
|
|
|
#
|
|
# Bug #8143: deleting '0000-00-00' values using IS NULL
|
|
#
|
|
|
|
create table t1(a date not null);
|
|
insert into t1 values (0);
|
|
select * from t1 where a is null;
|
|
delete from t1 where a is null;
|
|
select count(*) from t1;
|
|
drop table t1;
|
|
|
|
#
|
|
# Bug #26186: delete order by, sometimes accept unknown column
|
|
#
|
|
CREATE TABLE t1 (a INT); INSERT INTO t1 VALUES (1);
|
|
|
|
--error ER_BAD_FIELD_ERROR
|
|
DELETE FROM t1 ORDER BY x;
|
|
|
|
# even columns from a table not used in query (and not even existing)
|
|
--error ER_BAD_FIELD_ERROR
|
|
DELETE FROM t1 ORDER BY t2.x;
|
|
|
|
# subquery (as long as the subquery from is valid or DUAL)
|
|
--error ER_BAD_FIELD_ERROR
|
|
DELETE FROM t1 ORDER BY (SELECT x);
|
|
|
|
DROP TABLE t1;
|
|
|
|
#
|
|
# Bug #30234: Unexpected behavior using DELETE with AS and USING
|
|
# '
|
|
CREATE TABLE t1 (
|
|
a INT
|
|
);
|
|
|
|
CREATE TABLE t2 (
|
|
a INT
|
|
);
|
|
|
|
CREATE DATABASE db1;
|
|
CREATE TABLE db1.t1 (
|
|
a INT
|
|
);
|
|
INSERT INTO db1.t1 (a) SELECT * FROM t1;
|
|
|
|
CREATE DATABASE db2;
|
|
CREATE TABLE db2.t1 (
|
|
a INT
|
|
);
|
|
INSERT INTO db2.t1 (a) SELECT * FROM t2;
|
|
|
|
--error ER_PARSE_ERROR
|
|
DELETE FROM t1 alias USING t1, t2 alias WHERE t1.a = alias.a;
|
|
DELETE FROM alias USING t1, t2 alias WHERE t1.a = alias.a;
|
|
DELETE FROM t1, alias USING t1, t2 alias WHERE t1.a = alias.a;
|
|
--error ER_UNKNOWN_TABLE
|
|
DELETE FROM t1, t2 USING t1, t2 alias WHERE t1.a = alias.a;
|
|
--error ER_PARSE_ERROR
|
|
DELETE FROM db1.t1 alias USING db1.t1, db2.t1 alias WHERE db1.t1.a = alias.a;
|
|
DELETE FROM alias USING db1.t1, db2.t1 alias WHERE db1.t1.a = alias.a;
|
|
--error ER_UNKNOWN_TABLE
|
|
DELETE FROM db2.alias USING db1.t1, db2.t1 alias WHERE db1.t1.a = alias.a;
|
|
DELETE FROM t1 USING t1 WHERE a = 1;
|
|
SELECT * FROM t1;
|
|
--error ER_PARSE_ERROR
|
|
DELETE FROM t1 alias USING t1 alias WHERE a = 2;
|
|
SELECT * FROM t1;
|
|
|
|
DROP TABLE t1, t2;
|
|
DROP DATABASE db1;
|
|
DROP DATABASE db2;
|
|
|
|
#
|
|
# Bug 31742: delete from ... order by function call that causes an error,
|
|
# asserts server
|
|
#
|
|
|
|
CREATE FUNCTION f1() RETURNS INT RETURN 1;
|
|
CREATE TABLE t1 (a INT);
|
|
INSERT INTO t1 VALUES (0);
|
|
--error 1318
|
|
DELETE FROM t1 ORDER BY (f1(10)) LIMIT 1;
|
|
DROP TABLE t1;
|
|
DROP FUNCTION f1;
|
|
|
|
|
|
--echo #
|
|
--echo # Bug #49552 : sql_buffer_result cause crash + not found records
|
|
--echo # in multitable delete/subquery
|
|
--echo #
|
|
|
|
CREATE TABLE t1(a INT);
|
|
INSERT INTO t1 VALUES (1),(2),(3);
|
|
SET SESSION SQL_BUFFER_RESULT=1;
|
|
DELETE t1 FROM (SELECT SUM(a) a FROM t1) x,t1;
|
|
|
|
SET SESSION SQL_BUFFER_RESULT=DEFAULT;
|
|
SELECT * FROM t1;
|
|
DROP TABLE t1;
|
|
|
|
--echo End of 5.0 tests
|
|
|
|
#
|
|
# Bug#27525: table not found when using multi-table-deletes with aliases over
|
|
# several databas
|
|
# Bug#21148: MULTI-DELETE fails to resolve a table by alias if it's from a
|
|
# different database
|
|
#
|
|
|
|
--disable_warnings
|
|
DROP DATABASE IF EXISTS db1;
|
|
DROP DATABASE IF EXISTS db2;
|
|
DROP DATABASE IF EXISTS db3;
|
|
DROP DATABASE IF EXISTS db4;
|
|
DROP TABLE IF EXISTS t1, t2;
|
|
DROP PROCEDURE IF EXISTS count;
|
|
--enable_warnings
|
|
USE test;
|
|
CREATE DATABASE db1;
|
|
CREATE DATABASE db2;
|
|
|
|
CREATE TABLE db1.t1 (a INT, b INT);
|
|
INSERT INTO db1.t1 VALUES (1,1),(2,2),(3,3);
|
|
CREATE TABLE db1.t2 AS SELECT * FROM db1.t1;
|
|
CREATE TABLE db2.t1 AS SELECT * FROM db1.t2;
|
|
CREATE TABLE db2.t2 AS SELECT * FROM db2.t1;
|
|
CREATE TABLE t1 AS SELECT * FROM db2.t2;
|
|
CREATE TABLE t2 AS SELECT * FROM t1;
|
|
|
|
delimiter |;
|
|
CREATE PROCEDURE count_rows()
|
|
BEGIN
|
|
SELECT COUNT(*) AS "COUNT(db1.t1)" FROM db1.t1;
|
|
SELECT COUNT(*) AS "COUNT(db1.t2)" FROM db1.t2;
|
|
SELECT COUNT(*) AS "COUNT(db2.t1)" FROM db2.t1;
|
|
SELECT COUNT(*) AS "COUNT(db2.t2)" FROM db2.t2;
|
|
SELECT COUNT(*) AS "COUNT(test.t1)" FROM test.t1;
|
|
SELECT COUNT(*) AS "COUNT(test.t2)" FROM test.t2;
|
|
END|
|
|
delimiter ;|
|
|
|
|
#
|
|
# Testing without a selected database
|
|
#
|
|
|
|
CREATE DATABASE db3;
|
|
USE db3;
|
|
DROP DATABASE db3;
|
|
--error ER_NO_DB_ERROR
|
|
SELECT * FROM t1;
|
|
|
|
# Detect missing table references
|
|
|
|
--error ER_NO_DB_ERROR
|
|
DELETE a1,a2 FROM db1.t1, db2.t2;
|
|
--error ER_NO_DB_ERROR
|
|
DELETE a1,a2 FROM db1.t1, db2.t2;
|
|
--error ER_NO_DB_ERROR
|
|
DELETE a1,a2 FROM db1.t1 AS a1, db2.t2;
|
|
--error ER_NO_DB_ERROR
|
|
DELETE a1,a2 FROM db1.t1, db2.t2 AS a2;
|
|
--error ER_NO_DB_ERROR
|
|
DELETE a1,a2 FROM db3.t1 AS a1, db4.t2 AS a2;
|
|
--error ER_NO_DB_ERROR
|
|
DELETE a1,a2 FROM db3.t1 AS a1, db4.t2 AS a2;
|
|
|
|
--error ER_NO_DB_ERROR
|
|
DELETE FROM a1,a2 USING db1.t1, db2.t2;
|
|
--error ER_NO_DB_ERROR
|
|
DELETE FROM a1,a2 USING db1.t1, db2.t2;
|
|
--error ER_NO_DB_ERROR
|
|
DELETE FROM a1,a2 USING db1.t1 AS a1, db2.t2;
|
|
--error ER_NO_DB_ERROR
|
|
DELETE FROM a1,a2 USING db1.t1, db2.t2 AS a2;
|
|
--error ER_NO_DB_ERROR
|
|
DELETE FROM a1,a2 USING db3.t1 AS a1, db4.t2 AS a2;
|
|
--error ER_NO_DB_ERROR
|
|
DELETE FROM a1,a2 USING db3.t1 AS a1, db4.t2 AS a2;
|
|
|
|
# Ambiguous table references
|
|
|
|
--error ER_NO_DB_ERROR
|
|
DELETE a1 FROM db1.t1 AS a1, db2.t2 AS a1;
|
|
--error ER_NO_DB_ERROR
|
|
DELETE a1 FROM db1.a1, db2.t2 AS a1;
|
|
--error ER_NO_DB_ERROR
|
|
DELETE a1 FROM a1, db1.t1 AS a1;
|
|
--error ER_NO_DB_ERROR
|
|
DELETE t1 FROM db1.t1, db2.t1 AS a1;
|
|
--error ER_NO_DB_ERROR
|
|
DELETE t1 FROM db1.t1 AS a1, db2.t1 AS a2;
|
|
--error ER_NO_DB_ERROR
|
|
DELETE t1 FROM db1.t1, db2.t1;
|
|
|
|
# Test all again, now with a selected database
|
|
|
|
USE test;
|
|
|
|
# Detect missing table references
|
|
|
|
--error ER_UNKNOWN_TABLE
|
|
DELETE a1,a2 FROM db1.t1, db2.t2;
|
|
--error ER_UNKNOWN_TABLE
|
|
DELETE a1,a2 FROM db1.t1, db2.t2;
|
|
--error ER_UNKNOWN_TABLE
|
|
DELETE a1,a2 FROM db1.t1 AS a1, db2.t2;
|
|
--error ER_UNKNOWN_TABLE
|
|
DELETE a1,a2 FROM db1.t1, db2.t2 AS a2;
|
|
--error ER_NO_SUCH_TABLE
|
|
DELETE a1,a2 FROM db3.t1 AS a1, db4.t2 AS a2;
|
|
--error ER_NO_SUCH_TABLE
|
|
DELETE a1,a2 FROM db3.t1 AS a1, db4.t2 AS a2;
|
|
|
|
--error ER_UNKNOWN_TABLE
|
|
DELETE FROM a1,a2 USING db1.t1, db2.t2;
|
|
--error ER_UNKNOWN_TABLE
|
|
DELETE FROM a1,a2 USING db1.t1, db2.t2;
|
|
--error ER_UNKNOWN_TABLE
|
|
DELETE FROM a1,a2 USING db1.t1 AS a1, db2.t2;
|
|
--error ER_UNKNOWN_TABLE
|
|
DELETE FROM a1,a2 USING db1.t1, db2.t2 AS a2;
|
|
--error ER_NO_SUCH_TABLE
|
|
DELETE FROM a1,a2 USING db3.t1 AS a1, db4.t2 AS a2;
|
|
--error ER_NO_SUCH_TABLE
|
|
DELETE FROM a1,a2 USING db3.t1 AS a1, db4.t2 AS a2;
|
|
|
|
# Ambiguous table references
|
|
|
|
--error ER_NONUNIQ_TABLE
|
|
DELETE a1 FROM db1.t1 AS a1, db2.t2 AS a1;
|
|
--error ER_NO_SUCH_TABLE
|
|
DELETE a1 FROM db1.a1, db2.t2 AS a1;
|
|
--error ER_NONUNIQ_TABLE
|
|
DELETE a1 FROM a1, db1.t1 AS a1;
|
|
--error ER_UNKNOWN_TABLE
|
|
DELETE t1 FROM db1.t1, db2.t1 AS a1;
|
|
--error ER_UNKNOWN_TABLE
|
|
DELETE t1 FROM db1.t1 AS a1, db2.t1 AS a2;
|
|
--error ER_UNKNOWN_TABLE
|
|
DELETE t1 FROM db1.t1, db2.t1;
|
|
|
|
# Test multiple-table cross database deletes
|
|
|
|
--disable_ps2_protocol
|
|
DELETE t1 FROM db1.t2 AS t1, db2.t2 AS t2 WHERE t2.a = 1 AND t1.a = t2.a;
|
|
SELECT ROW_COUNT();
|
|
CALL count_rows();
|
|
DELETE a1, a2 FROM db2.t1 AS a1, t2 AS a2 WHERE a1.a = 2 AND a2.a = 2;
|
|
SELECT ROW_COUNT();
|
|
CALL count_rows();
|
|
|
|
DROP DATABASE db1;
|
|
DROP DATABASE db2;
|
|
DROP PROCEDURE count_rows;
|
|
DROP TABLE t1, t2;
|
|
--enable_ps2_protocol
|
|
|
|
--echo #
|
|
--echo # Bug#46958: Assertion in Diagnostics_area::set_ok_status, trigger,
|
|
--echo # merge table
|
|
--echo #
|
|
CREATE TABLE t1 ( a INT );
|
|
CREATE TABLE t2 ( a INT );
|
|
CREATE TABLE t3 ( a INT );
|
|
|
|
INSERT INTO t1 VALUES (1), (2);
|
|
INSERT INTO t2 VALUES (1), (2);
|
|
INSERT INTO t3 VALUES (1), (2);
|
|
|
|
CREATE TRIGGER tr1 BEFORE DELETE ON t2
|
|
FOR EACH ROW INSERT INTO no_such_table VALUES (1);
|
|
|
|
--error ER_NO_SUCH_TABLE
|
|
DELETE t1, t2, t3 FROM t1, t2, t3;
|
|
|
|
SELECT * FROM t1;
|
|
SELECT * FROM t2;
|
|
SELECT * FROM t3;
|
|
|
|
DROP TABLE t1, t2, t3;
|
|
|
|
CREATE TABLE t1 ( a INT );
|
|
CREATE TABLE t2 ( a INT );
|
|
CREATE TABLE t3 ( a INT );
|
|
|
|
INSERT INTO t1 VALUES (1), (2);
|
|
INSERT INTO t2 VALUES (1), (2);
|
|
INSERT INTO t3 VALUES (1), (2);
|
|
|
|
CREATE TRIGGER tr1 AFTER DELETE ON t2
|
|
FOR EACH ROW INSERT INTO no_such_table VALUES (1);
|
|
|
|
--error ER_NO_SUCH_TABLE
|
|
DELETE t1, t2, t3 FROM t1, t2, t3;
|
|
|
|
SELECT * FROM t1;
|
|
SELECT * FROM t2;
|
|
SELECT * FROM t3;
|
|
|
|
DROP TABLE t1, t2, t3;
|
|
|
|
--echo #
|
|
--echo # Bug #46425 crash in Diagnostics_area::set_ok_status,
|
|
--echo # empty statement, DELETE IGNORE
|
|
--echo #
|
|
|
|
CREATE table t1 (i INTEGER);
|
|
|
|
INSERT INTO t1 VALUES (1);
|
|
|
|
--delimiter |
|
|
|
|
CREATE TRIGGER tr1 AFTER DELETE ON t1 FOR EACH ROW
|
|
BEGIN
|
|
INSERT INTO t1 SELECT * FROM t1 AS A;
|
|
END |
|
|
|
|
--delimiter ;
|
|
--error ER_CANT_UPDATE_USED_TABLE_IN_SF_OR_TRG
|
|
DELETE IGNORE FROM t1;
|
|
|
|
DROP TABLE t1;
|
|
|
|
--echo #
|
|
--echo # Bug #53450: Crash/assertion
|
|
--echo # "virtual int ha_myisam::index_first(uchar*)") at assert.c:81
|
|
--echo #
|
|
|
|
CREATE TABLE t1 (a INT, b INT, c INT,
|
|
INDEX(a), INDEX(b), INDEX(c));
|
|
INSERT INTO t1 VALUES (1,2,3), (4,5,6), (7,8,9);
|
|
|
|
DELETE FROM t1 WHERE a = 10 OR b = 20 ORDER BY c LIMIT 1;
|
|
|
|
DROP TABLE t1;
|
|
|
|
--echo #
|
|
--echo # Bug #53034: Multiple-table DELETE statements not accepting
|
|
--echo # "Access compatibility" syntax
|
|
--echo #
|
|
|
|
CREATE TABLE t1 (id INT);
|
|
CREATE TABLE t2 LIKE t1;
|
|
CREATE TABLE t3 LIKE t1;
|
|
|
|
DELETE FROM t1.*, test.t2.*, a.* USING t1, t2, t3 AS a;
|
|
|
|
DROP TABLE t1, t2, t3;
|
|
|
|
--echo End of 5.1 tests
|
|
|
|
|
|
--echo #
|
|
--echo # Bug#51099 Assertion in mysql_multi_delete_prepare()
|
|
--echo #
|
|
|
|
--disable_warnings
|
|
DROP TABLE IF EXISTS t1, t2;
|
|
DROP VIEW IF EXISTS v1, v2;
|
|
--enable_warnings
|
|
|
|
CREATE TABLE t1(a INT);
|
|
CREATE TABLE t2(b INT);
|
|
CREATE VIEW v1 AS SELECT a, b FROM t1, t2;
|
|
CREATE VIEW v2 AS SELECT a FROM v1;
|
|
|
|
# This is a normal delete
|
|
--error ER_VIEW_DELETE_MERGE_VIEW
|
|
DELETE FROM v2;
|
|
# This is a multi table delete, check that we get the same error
|
|
# This caused the assertion.
|
|
--error ER_VIEW_DELETE_MERGE_VIEW
|
|
DELETE v2 FROM v2;
|
|
|
|
DROP VIEW v2, v1;
|
|
DROP TABLE t1, t2;
|
|
|
|
--echo End of 5.5 tests
|
|
|
|
--echo #
|
|
--echo # MDEV-30586: DELETE with WHERE containing nested subquery
|
|
--echo # with set function aggregated in outer subquery
|
|
--echo #
|
|
|
|
create table t1 (a int);
|
|
insert into t1 values (3), (7), (1);
|
|
|
|
create table t2 (b int);
|
|
insert into t2 values (2), (1), (4), (7);
|
|
|
|
create table t3 (a int, b int);
|
|
insert into t3 values (2,10), (7,30), (2,30), (1,10), (7,40);
|
|
|
|
let $c=
|
|
t1.a in (select t3.a from t3 group by t3.a
|
|
having t3.a > any (select t2.b from t2
|
|
where t2.b*10 < sum(t3.b)));
|
|
|
|
eval
|
|
select * from t1
|
|
where $c;
|
|
|
|
eval
|
|
delete from t1
|
|
where $c;
|
|
|
|
eval
|
|
select * from t1
|
|
where $c;
|
|
|
|
eval
|
|
update t1 set t1.a=t1.a+10
|
|
where $c;
|
|
|
|
drop table t1,t2,t3;
|
|
|
|
--echo End of 10.4 tests
|
|
|
|
--echo #
|
|
--echo # MDEV-26459: Assertion `block_size <= 0xFFFFFFFFL' failed
|
|
--echo # in calculate_block_sizes for 10.7 only
|
|
--echo #
|
|
|
|
SET @sort_buffer_size_save= @@sort_buffer_size;
|
|
--disable_warnings
|
|
SET sort_buffer_size=1125899906842624;
|
|
--enable_warnings
|
|
CREATE TABLE t1 (a INT,b CHAR,KEY(a,b));
|
|
DELETE a1 FROM t1 AS a1,t1 AS a2 WHERE a1.a=a2.a;
|
|
DROP TABLE t1;
|
|
SET sort_buffer_size= @sort_buffer_size_save;
|
|
|
|
--echo # End of 10.11 tests
|
|
|
|
--echo #
|
|
--echo # MDEV-29428: DELETE with ORDER BY without LIMIT clause
|
|
--echo #
|
|
|
|
create table t1 (c1 integer, c2 integer, c3 integer);
|
|
|
|
insert into t1 values
|
|
(1,1,1), (1,2,2), (1,3,3), (2,1,4), (2,2,5), (2,3,6), (2,4,7), (2,5,8);
|
|
|
|
create temporary table t select * from t1;
|
|
|
|
let $q1=
|
|
delete from t1 order by c2;
|
|
eval explain $q1;
|
|
eval $q1;
|
|
select *from t1;
|
|
|
|
delete from t1;
|
|
insert into t1 select * from t;
|
|
|
|
let $q2=
|
|
delete from t1
|
|
where exists (select 'X' from t1 a where a.c2 = t1.c2) and c2 >= 3;
|
|
eval explain $q2;
|
|
eval $q2;
|
|
select *from t1;
|
|
|
|
delete from t1;
|
|
insert into t1 select * from t;
|
|
|
|
let $q3=
|
|
delete from t1
|
|
where exists (select 'X' from t1 a where a.c2 = t1.c2) and c2 >= 3
|
|
order by c2;
|
|
eval explain $q3;
|
|
eval $q3;
|
|
select *from t1;
|
|
|
|
drop table t1;
|
|
|
|
--echo End of 11.1 tests
|
|
|
|
--echo #
|
|
--echo # MDEV-33988 DELETE to support table aliases
|
|
--echo #
|
|
# Test from MySQL Bug#27455809; DELETE FROM ...WHERE NOT EXISTS WITH TABLE ALIAS CREATES AN ERROR 1064 (42000
|
|
|
|
CREATE TABLE t1 (c1 INT);
|
|
INSERT INTO t1 VALUES (1), (2);
|
|
SELECT * FROM t1;
|
|
|
|
DELETE FROM t1 AS a1 WHERE a1.c1 = 2;
|
|
SELECT * FROM t1;
|
|
|
|
CREATE TABLE t2 (c2 INT);
|
|
INSERT INTO t2 VALUES (1), (2);
|
|
SELECT * FROM t2;
|
|
|
|
DELETE FROM t2 a2 WHERE NOT EXISTS (SELECT * FROM t1 WHERE t1.c1 = a2.c2);
|
|
SELECT * FROM t2;
|
|
|
|
DROP TABLE t1, t2;
|
|
|
|
--echo End of 11.6 tests
|
|
|
|
--echo #
|
|
--echo # MDEV-25008: Delete query gets stuck on mariadb, same query works
|
|
--echo # on MySQL 8.0.21
|
|
--echo #
|
|
|
|
--source include/have_sequence.inc
|
|
--source include/have_innodb.inc
|
|
|
|
# original case
|
|
CREATE TABLE t1 (
|
|
id int NOT NULL PRIMARY KEY,
|
|
item_id varchar(100),
|
|
seller_name varchar(400),
|
|
variant varchar(400),
|
|
FULLTEXT KEY t1_serial_IDX (item_id,seller_name,variant)
|
|
)engine=innodb;
|
|
|
|
insert into t1 select seq,seq,seq,seq from seq_1_to_10000;
|
|
|
|
# Masking the `rows` column as the value might vary a bit
|
|
--replace_column 9 #
|
|
explain
|
|
DELETE FROM t1 WHERE id NOT IN
|
|
(SELECT m FROM (SELECT max(id) m FROM t1 GROUP BY item_id, seller_name, variant) AS innertable);
|
|
|
|
drop table t1;
|
|
|
|
# example of not full table
|
|
create table t1 (a int primary key, b int, c int, key(b));
|
|
insert into t1 select seq, seq, seq from seq_1_to_20000;
|
|
create table t2 as select * from t1;
|
|
explain delete from t1 where b <= 2 and a not in (select b from t2);
|
|
explain delete from t1 where b <= 3 and a not in (select b from t2);
|
|
drop table t1, t2;
|
|
|
|
--echo # End of 11.7 tests
|