Commit 1e0a72a1 authored by Lena Startseva's avatar Lena Startseva Committed by Igor Babaev

MDEV-29390: Improve coverage for UPDATE and DELETE statements in MTR test suites

Created tests for "delete" based on update_use_source.test

For the update_use_source.test tests, data recovery in the table has been changed
from a rollback transaction to a complete delete and re-insert of the data with
optimize table. Cases are now being checked on three engines.

Added tests for update/delete with LooseScan and DuplicateWeedout optimization strategies
Added tests for engine MEMORY on delete and update
Added tests for multi-update with JSON_TABLE
Added tests for multi-update and multi-delete for engine Connect
parent 9a3fd1df
create table t1 (c1 integer, c2 integer, c3 integer);
insert into t1(c1,c2,c3)
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);
insert into t1 select c1+10,c2,c3+10 from t1;
insert into t1 select c1+20,c2+1,c3+20 from t1;
analyze table t1 persistent for all;
create view v1 as select * from t1 where c2=2;
--echo #######################################
--echo # Test without any index #
--echo #######################################
--source include/delete_use_source_cases.inc
--source include/delete_use_source_cases_non_innodb.inc
--echo #######################################
--echo # Test with an index #
--echo #######################################
create index t1_c2 on t1 (c2,c1);
--source include/delete_use_source_cases.inc
--source include/delete_use_source_cases_non_innodb.inc
--echo #######################################
--echo # Test with a primary key #
--echo #######################################
drop index t1_c2 on t1;
alter table t1 add primary key (c3);
--source include/delete_use_source_cases.inc
--source include/delete_use_source_cases_non_innodb.inc
drop view v1;
drop table t1;
--echo #
--echo # Test on dynamic columns (blob)
--echo #
create table assets (
item_name varchar(32) primary key, -- A common attribute for all items
dynamic_cols blob -- Dynamic columns will be stored here
);
INSERT INTO assets
VALUES ('MariaDB T-shirt',
COLUMN_CREATE('color', 'blue', 'size', 'XL'));
INSERT INTO assets
VALUES ('Thinkpad Laptop',
COLUMN_CREATE('color', 'black', 'price', 500));
INSERT INTO assets
VALUES ('Fridge',
COLUMN_CREATE('color', 'white', 'warranty', '5 years'));
INSERT INTO assets
VALUES ('Microwave',
COLUMN_CREATE('warranty', '3 years'));
SELECT item_name, COLUMN_GET(dynamic_cols, 'color' as char) AS color
FROM assets ORDER BY item_name;
UPDATE assets SET dynamic_cols=COLUMN_DELETE(dynamic_cols, 'color')
WHERE item_name='Fridge';
SELECT item_name, COLUMN_GET(dynamic_cols, 'color' as char) AS color
FROM assets ORDER BY item_name;
DELETE FROM assets
WHERE item_name in
(select b.item_name from assets b
where COLUMN_GET(b.dynamic_cols, 'color' as char) ='black');
SELECT item_name, COLUMN_GET(dynamic_cols, 'color' as char) AS color
FROM assets ORDER BY item_name;
DELETE FROM assets WHERE item_name='Microwave';
SELECT item_name, COLUMN_GET(dynamic_cols, 'color' as char) AS color
FROM assets ORDER BY item_name;
drop table assets ;
--echo #
--echo # Test on fulltext columns
--echo #
CREATE TABLE ft2(copy TEXT,FULLTEXT(copy));
INSERT INTO ft2(copy) VALUES
('MySQL vs MariaDB database'),
('Oracle vs MariaDB database'),
('PostgreSQL vs MariaDB database'),
('MariaDB overview'),
('Foreign keys'),
('Primary keys'),
('Indexes'),
('Transactions'),
('Triggers');
SELECT * FROM ft2 WHERE MATCH(copy) AGAINST('database');
DELETE FROM ft2 WHERE MATCH(copy) AGAINST('database');
SELECT * FROM ft2 WHERE MATCH(copy) AGAINST('database');
drop table ft2;
--echo #
--echo # Delete with value from subquery on the same table
--echo #
analyze table t1 persistent for all;
let $c = c1=(select a.c3 from t1 a where a.c3 = t1.c3);
eval create table tmp as select * from t1 where $c;
let $q = delete from t1 where $c;
eval explain select * from t1 where $c;
eval explain $q;
--enable_info ONCE
eval $q;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop table tmp;
--echo #
--echo # Delete with EXISTS subquery over the updated table
--echo # in WHERE + possibly sargable condition
--echo #
analyze table t1 persistent for all;
let $c = c1 = 1 and exists (select 'X' from t1 a where a.c1 = t1.c2);
eval create table tmp as select * from t1 where $c;
let $q = delete from t1 where $c;
eval explain select * from t1 where $c;
eval explain $q;
eval analyze $q;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop table tmp;
--echo #
--echo # Delete with IN predicand over the updated table in WHERE
--echo #
let $c = c3 in (select distinct a.c1 from t1 a where t1.c2=a.c2);
eval create table tmp as select * from t1 where $c;
let $q = delete from t1 where $c;
eval explain select * from t1 where $c;
eval explain $q;
--enable_info ONCE
eval $q;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop table tmp;
--echo #
--echo # Delete with a limit - can be deleted
--echo #
let $c = c1 in (select a.c2 from t1 a where a.c2 = t1.c3) limit 1;
eval create table tmp as select * from t1 where $c;
let $q = delete from t1 where $c;
eval explain select * from t1 where $c;
eval explain $q;
eval analyze $q;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop table tmp;
--echo #
--echo # Delete with a limit and an order by
--echo #
let $c = c1 in (select a.c2 from t1 a where a.c3 = t1.c3)
order by c3 desc limit 1;
eval create table tmp as select * from t1 where $c;
let $q = delete from t1 where $c;
eval explain select * from t1 where $c;
eval explain $q;
--enable_info ONCE
eval $q;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop table tmp;
--echo #
--echo # Delete: 2 execution of PS
--echo #
prepare create_tmp_stmt from
"create table tmp as select * from t1
where c2=(select a.c3 from t1 a where a.c3 = ?)";
prepare delete_t1_stmt from
"delete from t1 where c2=(select a.c3 from t1 a where a.c3 = ?)";
set @a:=5;
execute create_tmp_stmt using @a;
execute delete_t1_stmt using @a;
execute delete_t1_stmt using @a;
--sorted_result
select * from t1;
prepare insert_tmp_stmt from
"insert into tmp(c1,c2,c3) select * from t1
where c2=(select a.c3 from t1 a where a.c3 = ?)";
set @a:=2;
execute insert_tmp_stmt using @a;
execute delete_t1_stmt using @a;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
--sorted_result
select * from t1;
drop table tmp;
--echo #
--echo # Delete in stored procedure
--echo #
delimiter //;
create procedure sp()
begin
delete from t1 where c1 in (select a.c2 from t1 a where a.c3 = t1.c3)
order by c3 desc limit 1;
end
//
delimiter ;//
create table tmp as select * from t1
where c1 in (select a.c2 from t1 a where a.c3 = t1.c3)
order by c3 desc limit 1;
CALL sp;
insert into tmp(c1,c2,c3) select * from t1
where c1 in (select a.c2 from t1 a where a.c3 = t1.c3)
order by c3 desc limit 1;
CALL sp;
insert into tmp(c1,c2,c3) select * from t1
where c1 in (select a.c2 from t1 a where a.c3 = t1.c3)
order by c3 desc limit 1;
CALL sp;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop procedure sp;
drop table tmp;
--echo #
--echo # Delete in stored function
--echo #
delimiter //;
create function f1(IN a INT) returns int
begin
delete from t1 where c3 < a order by c3 limit 1;
return 1;
end;//
delimiter ;//
set @a:=7;
create table tmp as select * from t1 where c3 < @a
order by c3 limit 1;
select f1(@a);
insert into tmp(c1,c2,c3) select * from t1 where c3 < @a
order by c3 limit 1;
select f1(@a);
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop function f1;
drop table tmp;
--echo #
--echo # Delete in trigger
--echo #
create table t2 (c1 integer);
insert into t2(c1) values (1), (2), (3), (4), (5), (6), (7), (8);
CREATE TABLE cnt(del integer);
INSERT INTO cnt VALUES(0);
CREATE TRIGGER tr1 AFTER DELETE ON t1 FOR EACH ROW
UPDATE cnt SET del=del+1;
CREATE TRIGGER tr2 AFTER DELETE ON t1 FOR EACH ROW
DELETE FROM t2 WHERE c1> (SELECT count(*)-1 FROM t2);
CREATE TABLE tmp as SELECT * FROM t1 WHERE c2>=3;
--enable_info ONCE
DELETE FROM t1 WHERE c2>=3;
--sorted_result
select * from t1;
--sorted_result
SELECT * FROM t2;
SELECT * FROM cnt;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
DROP TRIGGER tr1;
DROP TRIGGER tr2;
drop table t2, cnt, tmp;
--echo #
--echo # Delete with a reference to view in subquery
--echo #
let $c = t1.c2 in ( select max(a.c2) from v1 a
where a.c1 = t1.c1);
eval create table tmp as select * from t1 where $c;
let $q = delete from t1 where $c;
eval explain select * from t1 where $c;
eval explain $q;
eval analyze $q;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop table tmp;
--echo #
--echo # Delete with value from subquery on the same table
--echo #
analyze table t1 persistent for all;
let $c = c1=(select a.c3 from t1 a where a.c3 = t1.c3);
eval create table tmp as select * from t1 where $c;
let $q = delete from t1 where $c;
eval explain select * from t1 where $c;
eval explain $q;
--enable_info ONCE
eval $q;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop table tmp;
--echo #
--echo # Delete with EXISTS subquery over the updated table
--echo # in WHERE + possibly sargable condition
--echo #
analyze table t1 persistent for all;
let $c = c1 = 1 and exists (select 'X' from t1 a where a.c1 = t1.c2);
eval create table tmp as select * from t1 where $c;
let $q = delete from t1 where $c;
eval explain select * from t1 where $c;
eval explain $q;
--enable_info ONCE
eval $q;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop table tmp;
--echo #
--echo # Delete with EXISTS subquery over the updated table
--echo # in WHERE + non-sargable condition
--echo #
analyze table t1 persistent for all;
let $c = exists (select 'X' from t1 a where a.c2 = t1.c2) and c2 = 3;
eval create table tmp as select * from t1 where $c;
let $q = delete from t1 where $c;
eval explain select * from t1 where $c;
eval explain $q;
--enable_info ONCE
eval $q;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop table tmp;
--echo #
--echo # Delete with order by
--echo #
analyze table t1 persistent for all;
let $c = exists (select 'X' from t1 a where a.c2 = t1.c2)
and c2 >= 3 order by c2;
eval create table tmp as select * from t1 where $c;
let $q = delete from t1 where $c;
eval explain select * from t1 where $c;
eval explain $q;
--enable_info ONCE
eval $q;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop table tmp;
--echo #
--echo # Delete with IN predicand over the updated table in WHERE
--echo #
let $c = c3 in (select distinct a.c1 from t1 a where t1.c2=a.c2);
eval create table tmp as select * from t1 where $c;
let $q = delete from t1 where $c;
eval explain select * from t1 where $c;
eval explain $q;
--enable_info ONCE
eval $q;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop table tmp;
--echo #
--echo # Delete with a limit - can be deleted
--echo #
let $c = c1 in (select a.c2 from t1 a where a.c2 = t1.c3) limit 1;
eval create table tmp as select * from t1 where $c;
let $q = delete from t1 where $c;
eval explain select * from t1 where $c;
eval explain $q;
--enable_info ONCE
eval $q;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop table tmp;
--echo #
--echo # Delete with a limit and an order by
--echo #
let $c = c1 in (select a.c2 from t1 a where a.c3 = t1.c3)
order by c3 desc limit 1;
eval create table tmp as select * from t1 where $c;
let $q = delete from t1 where $c;
eval explain select * from t1 where $c;
eval explain $q;
--enable_info ONCE
eval $q;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop table tmp;
--echo #
--echo # Delete: 2 execution of PS
--echo #
prepare create_tmp_stmt from
"create table tmp as select * from t1
where c2=(select a.c3 from t1 a where a.c3 = ?)";
prepare delete_t1_stmt from
"delete from t1 where c2=(select a.c3 from t1 a where a.c3 = ?)";
set @a:=5;
execute create_tmp_stmt using @a;
execute delete_t1_stmt using @a;
execute delete_t1_stmt using @a;
--sorted_result
select * from t1;
prepare insert_tmp_stmt from
"insert into tmp(c1,c2,c3) select * from t1
where c2=(select a.c3 from t1 a where a.c3 = ?)";
set @a:=2;
execute insert_tmp_stmt using @a;
execute delete_t1_stmt using @a;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
--sorted_result
select * from t1;
drop table tmp;
--echo #
--echo # Delete in stored procedure
--echo #
delimiter //;
create procedure sp()
begin
delete from t1 where c1 in (select a.c2 from t1 a where a.c3 = t1.c3)
order by c3 desc limit 1;
end
//
delimiter ;//
create table tmp as select * from t1
where c1 in (select a.c2 from t1 a where a.c3 = t1.c3)
order by c3 desc limit 1;
CALL sp;
insert into tmp(c1,c2,c3) select * from t1
where c1 in (select a.c2 from t1 a where a.c3 = t1.c3)
order by c3 desc limit 1;
CALL sp;
insert into tmp(c1,c2,c3) select * from t1
where c1 in (select a.c2 from t1 a where a.c3 = t1.c3)
order by c3 desc limit 1;
CALL sp;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop procedure sp;
drop table tmp;
--echo #
--echo # Delete in stored function
--echo #
delimiter //;
create function f1(IN a INT) returns int
begin
delete from t1 where c3 < a order by c3 limit 1;
return 1;
end;//
delimiter ;//
set @a:=7;
create table tmp as select * from t1 where c3 < @a
order by c3 limit 1;
select f1(@a);
insert into tmp(c1,c2,c3) select * from t1 where c3 < @a
order by c3 limit 1;
select f1(@a);
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop function f1;
drop table tmp;
--echo #
--echo # Delete in trigger
--echo #
create table t2 (c1 integer);
insert into t2(c1) values (1), (2), (3), (4), (5), (6), (7), (8);
CREATE TABLE cnt(del integer);
INSERT INTO cnt VALUES(0);
CREATE TRIGGER tr1 AFTER DELETE ON t1 FOR EACH ROW
UPDATE cnt SET del=del+1;
CREATE TRIGGER tr2 AFTER DELETE ON t1 FOR EACH ROW
DELETE FROM t2 WHERE c1> (SELECT count(*)-1 FROM t2);
CREATE TABLE tmp as SELECT * FROM t1 WHERE c2>=3;
--enable_info ONCE
DELETE FROM t1 WHERE c2>=3;
--sorted_result
select * from t1;
--sorted_result
SELECT * FROM t2;
SELECT * FROM cnt;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
DROP TRIGGER tr1;
DROP TRIGGER tr2;
drop table t2, cnt, tmp;
--echo #
--echo Delete with a reference to view in subquery
--echo #
let $c = t1.c2 in ( select max(a.c2) from v1 a
where a.c1 = t1.c1);
eval create table tmp as select * from t1 where $c;
let $q = delete from t1 where $c;
eval explain select * from t1 where $c;
eval explain $q;
--enable_info ONCE
eval $q;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop table tmp;
--echo #
--echo # Delete from view
--echo #
analyze table t1 persistent for all;
let $c = v1.c1 in
(select max(a.c1) from t1 a where a.c2 = v1.c2) and c3 = 5;
eval create table tmp as select * from v1 where $c;
let $q = delete from v1 where $c;
eval explain select * from v1 where $c;
eval explain $q;
--enable_info ONCE
eval $q;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop table tmp;
--echo #
--echo # Delete from view using reference
--echo # to the same view in subquery
--echo #
analyze table t1 persistent for all;
let $c = v1.c2 in (select max(a.c2) from t1 a where a.c3 = v1.c3)
and c1 = 2
and exists (select 'X' from v1 a where a.c1 = v1.c1);
eval create table tmp as select * from v1 where $c;
let $q = delete from v1 where $c;
eval explain select * from v1 where $c;
eval explain $q;
--enable_info ONCE
eval $q;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop table tmp;
--echo #
--echo # Delete with EXISTS subquery over the updated table
--echo # in WHERE + non-sargable condition
--echo #
analyze table t1 persistent for all;
let $c = exists (select 'X' from t1 a where a.c2 = t1.c2) and c2 = 3;
eval create table tmp as select * from t1 where $c;
let $q = delete from t1 where $c;
eval explain select * from t1 where $c;
eval explain $q;
--enable_info ONCE
eval $q;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop table tmp;
--echo #
--echo # Delete with order by
--echo #
analyze table t1 persistent for all;
let $c = exists (select 'X' from t1 a where a.c2 = t1.c2)
and c2 >= 3 order by c2;
eval create table tmp as select * from t1 where $c;
let $q = delete from t1 where $c;
--replace_column 9 #
eval explain select * from t1 where $c;
--replace_column 9 #
eval explain $q;
--replace_column 9 #
eval analyze $q;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop table tmp;
--echo #
--echo # Delete from view
--echo #
analyze table t1 persistent for all;
let $c = v1.c1 in
(select max(a.c1) from t1 a where a.c2 = v1.c2) and c3 = 5;
eval create table tmp as select * from v1 where $c;
let $q = delete from v1 where $c;
eval explain select * from v1 where $c;
eval explain $q;
--enable_info ONCE
eval $q;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop table tmp;
--echo #
--echo # Delete from view using reference
--echo # to the same view in subquery
--echo #
analyze table t1 persistent for all;
let $c = v1.c2 in (select max(a.c2) from t1 a where a.c3 = v1.c3)
and c1 = 2
and exists (select 'X' from v1 a where a.c1 = v1.c1);
eval create table tmp as select * from v1 where $c;
let $q = delete from v1 where $c;
--replace_column 9 #
eval explain select * from v1 where $c;
--replace_column 9 #
eval explain $q;
--replace_column 9 #
eval analyze $q;
--sorted_result
select * from t1;
insert into t1(c1,c2,c3) select c1,c2,c3 from tmp;
drop table tmp;
create table t1 (c1 integer, c2 integer, c3 integer);
insert into t1(c1,c2,c3)
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);
insert into t1 select c1+10,c2,c3+10 from t1;
insert into t1 select c1+20,c2+1,c3+20 from t1;
analyze table t1 persistent for all;
create view v1 as select * from t1 where c2=2;
--echo #######################################
--echo # Test without any index #
--echo #######################################
--source include/delete_use_source_cases.inc
--echo #######################################
--echo # Test with an index #
--echo #######################################
create index t1_c2 on t1 (c2,c1);
--source include/delete_use_source_cases.inc
--echo #######################################
--echo # Test with a primary key #
--echo #######################################
drop index t1_c2 on t1;
alter table t1 add primary key (c3);
--source include/delete_use_source_cases.inc
drop view v1;
drop table t1;
--echo #
--echo # Test on dynamic columns (blob)
--echo #
create table assets (
item_name varchar(32) primary key, -- A common attribute for all items
dynamic_cols blob -- Dynamic columns will be stored here
);
INSERT INTO assets
VALUES ('MariaDB T-shirt',
COLUMN_CREATE('color', 'blue', 'size', 'XL'));
INSERT INTO assets
VALUES ('Thinkpad Laptop',
COLUMN_CREATE('color', 'black', 'price', 500));
INSERT INTO assets
VALUES ('Fridge',
COLUMN_CREATE('color', 'white', 'warranty', '5 years'));
INSERT INTO assets
VALUES ('Microwave',
COLUMN_CREATE('warranty', '3 years'));
SELECT item_name, COLUMN_GET(dynamic_cols, 'color' as char) AS color
FROM assets ORDER BY item_name;
UPDATE assets SET dynamic_cols=COLUMN_DELETE(dynamic_cols, 'color')
WHERE item_name='Fridge';
SELECT item_name, COLUMN_GET(dynamic_cols, 'color' as char) AS color
FROM assets ORDER BY item_name;
DELETE FROM assets
WHERE item_name in
(select b.item_name from assets b
where COLUMN_GET(b.dynamic_cols, 'color' as char) ='black');
SELECT item_name, COLUMN_GET(dynamic_cols, 'color' as char) AS color
FROM assets ORDER BY item_name;
DELETE FROM assets WHERE item_name='Microwave';
SELECT item_name, COLUMN_GET(dynamic_cols, 'color' as char) AS color
FROM assets ORDER BY item_name;
drop table assets ;
--echo #
--echo # Test on fulltext columns
--echo #
CREATE TABLE ft2(copy TEXT,FULLTEXT(copy));
INSERT INTO ft2(copy) VALUES
('MySQL vs MariaDB database'),
('Oracle vs MariaDB database'),
('PostgreSQL vs MariaDB database'),
('MariaDB overview'),
('Foreign keys'),
('Primary keys'),
('Indexes'),
('Transactions'),
('Triggers');
SELECT * FROM ft2 WHERE MATCH(copy) AGAINST('database');
DELETE FROM ft2 WHERE MATCH(copy) AGAINST('database');
SELECT * FROM ft2 WHERE MATCH(copy) AGAINST('database');
drop table ft2;
create table t1 (c1 integer, c2 integer, c3 integer);
insert into t1(c1,c2,c3)
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);
insert into t1 select c1+10,c2,c3+10 from t1;
insert into t1 select c1+20,c2+1,c3+20 from t1;
analyze table t1 persistent for all;
create view v1 as select * from t1 where c2=2;
--echo #######################################
--echo # Test without any index #
--echo #######################################
--source include/delete_use_source_cases_memory.inc
--echo #######################################
--echo # Test with an index #
--echo #######################################
create index t1_c2 on t1 (c2,c1);
--source include/delete_use_source_cases_memory.inc
--echo #######################################
--echo # Test with a primary key #
--echo #######################################
drop index t1_c2 on t1;
alter table t1 add primary key (c3);
--source include/delete_use_source_cases_memory.inc
drop view v1;
drop table t1;
# Include to test update with same table as source and target
--echo #
--echo # Update a with value from subquery on the same table, no search clause. ALL access
--echo #
#Enable view protocol after fix MDEV-29207
--disable_view_protocol
start transaction;
create table t1 (old_c1 integer,
old_c2 integer,
c1 integer,
c2 integer,
c3 integer);
create view v1 as select * from t1 where c2=2;
delimiter /;
create trigger trg_t1 before update on t1 for each row
begin
set new.old_c1=old.c1;
set new.old_c2=old.c2;
end;
/
delimiter ;/
insert into t1(c1,c2,c3)
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);
insert into t1 select NULL, NULL, c1+10,c2,c3+10 from t1;
insert into t1 select NULL, NULL, c1+20,c2+1,c3+20 from t1;
analyze table t1 persistent for all;
create table tmp as select * from t1;
--echo #######################################
--echo # Test without any index #
--echo #######################################
--source include/update_use_source_cases.inc
--echo #######################################
--echo # Test with an index #
--echo #######################################
create index t1_c2 on t1 (c2,c1);
analyze table t1;
--source include/update_use_source_cases.inc
--echo #######################################
--echo # Test with a primary key #
--echo #######################################
drop index t1_c2 on t1;
alter table t1 add primary key (c3);
analyze table t1;
--source include/update_use_source_cases.inc
--echo # Update with error "Subquery returns more than 1 row"
--error ER_SUBQUERY_NO_1_ROW
update t1 set c2=(select c2 from t1);
--sorted_result
select c1,c2,c3 from t1;
--echo # Update with error "Subquery returns more than 1 row"
--echo # and order by
--error ER_SUBQUERY_NO_1_ROW
update t1 set c2=(select c2 from t1) order by c3;
--sorted_result
select c1,c2,c3 from t1;
-- echo # Duplicate value on update a primary key
--error ER_DUP_ENTRY
update t1 set c3=0
where exists (select 'X' from t1 a where a.c2 = t1.c2) and c2 >= 3;
--sorted_result
select c1,c2,c3 from t1;
truncate table t1;
insert into t1 select * from tmp;
-- echo # Duplicate value on update a primary key with ignore
--enable_info ONCE
update t1
set c1=(select a.c3
from t1 a
where a.c3 = t1.c3);
select concat(old_c1,'->',c1),c3, case when c1 != old_c1 then '*' else ' ' end "Changed" from t1 ;
rollback;
--echo #
--echo # Update with search clause on the same table
--echo #
start transaction;
update ignore t1 set c3=0
where exists (select 'X' from t1 a where a.c2 = t1.c2) and c2 >= 3;
--sorted_result
select c1,c2,c3 from t1;
truncate table t1;
insert into t1 select * from tmp;
-- echo # Duplicate value on update a primary key and limit
--error ER_DUP_ENTRY
update t1 set c3=0
where exists (select 'X' from t1 a where a.c2 = t1.c2)
and c2 >= 3 limit 2;
--sorted_result
select c1,c2,c3 from t1;
truncate table t1;
insert into t1 select * from tmp;
-- echo # Duplicate value on update a primary key with ignore
-- echo # and limit
--enable_info ONCE
update t1
set c1=10
where c1 <2
and exists (select 'X'
from t1 a
where a.c1 = t1.c1);
select concat(old_c1,'->',c1),c3, case when c1 != old_c1 then '*' else ' ' end "Changed" from t1 ;
rollback;
--echo #
--echo # Update via RANGE or INDEX access if an index or a primary key exists
--echo #
explain update t1 set c1=0 where exists (select 'X' from t1 a where a.c2 = t1.c2) and c2 > 3;
start transaction;
update ignore t1 set c3=0
where exists (select 'X' from t1 a where a.c2 = t1.c2)
and c2 >= 3 limit 2;
--sorted_result
select c1,c2,c3 from t1;
truncate table t1;
insert into t1 select * from tmp;
--echo # Update no rows found
--enable_info ONCE
update t1 set c1=c1+10 where exists (select 'X' from t1 a where a.c2 = t1.c2) and c2 >= 3;
select concat(old_c1,'->',c1),c3, case when c1 != old_c1 then '*' else ' ' end "Changed" from t1;
rollback;
--echo #
--echo # Update with order by
--echo #
start transaction;
update t1 set c1=c1+10 where exists (select 'X' from t1 a where a.c2 = t1.c2) and c2 >= 3 order by c2;
select concat(old_c1,'->',c1),c3, case when c1 != old_c1 then '*' else ' ' end "Changed" from t1;
rollback;
--echo #
--echo Update using a view in subquery
--echo #
start transaction;
update t1 set c1=10
where c1 <2 and exists (select 'X' from t1 a where a.c1 = t1.c1 + 10);
--sorted_result
select c1,c2,c3 from t1;
truncate table t1;
insert into t1 select * from tmp;
--echo # Update no rows changed
drop trigger trg_t1;
--enable_info ONCE
update t1
set c1=c1 +(select max(a.c2)
from v1 a
where a.c1 = t1.c1) ;
select concat(old_c1,'->',c1),c3, case when c1 != old_c1 then '*' else ' ' end "Changed" from t1;
rollback;
update t1 set c1=c1
where c1 <2 and exists (select 'X' from t1 a where a.c1 = t1.c1);
--sorted_result
select c1,c2,c3 from t1;
truncate table t1;
insert into t1 select * from tmp;
--echo #
--echo # Update throw a view
--echo # Check call of after trigger
--echo #
start transaction;
--enable_info ONCE
update v1
set c1=c1 + (select max(a.c2)
from t1 a
where a.c1 = v1.c1) +10
where c3 > 3;
select concat(old_c1,'->',c1),c3, case when c1 != old_c1 then '*' else ' ' end "Changed" from t1;
rollback;
--echo #
--echo # Update through a view and using the view in subquery
--echo #
delimiter /;
create or replace trigger trg_t2 after update on t1 for each row
begin
declare msg varchar(100);
if (new.c3 = 5) then
set msg=concat('in after update trigger on ',new.c3);
SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = msg;
end if;
end;
/
delimiter ;/
--error 1644
start transaction;
--enable_info ONCE
update v1
set c1=c1 + 1
where c1 <2
and exists (select 'X'
from v1 a
where a.c1 = v1.c1);
select concat(old_c1,'->',c1),c3, case when c1 != old_c1 then '*' else ' ' end "Changed" from t1;
rollback;
update t1 set c1=2
where c3 in (select distinct a.c3 from t1 a where a.c1=t1.c1);
--sorted_result
select c1,c2,c3 from t1;
truncate table t1;
insert into t1 select * from tmp;
--echo #
--echo # Update through a view and using the view in subquery
--echo # Check update with order by and after trigger
--echo #
start transaction;
--enable_info ONCE
update v1
set c1=(select max(a.c1)+10
from v1 a
where a.c1 = v1.c1)
where c1 <10
and exists (select 'X'
from v1 a
where a.c2 = v1.c2);
select concat(old_c1,'->',c1),c3, case when c1 != old_c1 then '*' else ' ' end "Changed" from t1;
rollback;
--error 1644
update t1 set c1=2
where c3 in (select distinct a.c3 from t1 a where a.c1=t1.c1)
order by t1.c2, t1.c1;
--sorted_result
select c1,c2,c3 from t1;
truncate table t1;
insert into t1 select * from tmp;
drop view v1;
--echo #
--echo # Update of the index or primary key (c3)
--echo # Check update on view with check option
--echo #
start transaction;
explain update t1 set c3=c3+10 where c2 in (select distinct a.c2 from t1 a where t1.c1=a.c1);
--enable_info ONCE
update t1 set c3=c3+10 where c2 in (select distinct a.c2 from t1 a where t1.c1=a.c1);
select c3 from t1;
rollback;
create view v1 as select * from t1 where c2=2 with check option;
--echo #
--echo # update with a limit
--echo #
-- error 1369
update v1 set c2=3 where c1=1;
--sorted_result
select c1,c2,c3 from t1;
truncate table t1;
insert into t1 select * from tmp;
start transaction;
--enable_info ONCE
update t1
set c1=(select a.c3
from t1 a
where a.c3 = t1.c3)
limit 2;
select concat(old_c1,'->',c1),c3, case when c1 != old_c1 then '*' else ' ' end "Changed" from t1 ;
rollback;
-- error 1369
update v1 set c2=(select max(c3) from v1) where c1=1;
--sorted_result
select c1,c2,c3 from t1;
truncate table t1;
insert into t1 select * from tmp;
--echo #
--echo # update with a limit and an order by
--echo #
update v1 set c2=(select min(va.c3) from v1 va), c1=0 where c1=1;
--sorted_result
select c1,c2,c3 from t1;
truncate table t1;
insert into t1 select * from tmp;
start transaction;
--enable_info ONCE
update t1
set c1=(select a.c3
from t1 a
where a.c3 = t1.c3)
order by c3 desc limit 2;
select concat(old_c1,'->',c1),c3, case when c1 != old_c1 then '*' else ' ' end "Changed" from t1 ;
rollback;
--enable_view_protocol
drop table tmp;
drop view v1;
drop table t1;
--echo #
--echo # Update with value from subquery on the same table
--echo #
analyze table t1 persistent for all;
let $q = update t1 set c1=(select a.c3 from t1 a where a.c3 = t1.c3);
eval explain select * from t1;
eval explain $q;
--enable_info ONCE
eval $q;
select concat(old_c1,'->',c1),c3,
case when c1 != old_c1 then '*' else ' ' end "Changed" from t1;
truncate table t1;
insert into t1 select * from tmp;
--echo #
--echo # Update with EXISTS subquery over the updated table
--echo # in WHERE + possibly sargable condition
--echo #
analyze table t1 persistent for all;
let $c = c1 <2
and exists (select 'X' from t1 a where a.c1 = t1.c1);
let $q = update t1 set c1=10 where $c;
eval explain select * from t1 where $c;
eval explain $q;
--enable_info ONCE
eval $q;
select concat(old_c1,'->',c1),c3,
case when c1 != old_c1 then '*' else ' ' end "Changed" from t1;
truncate table t1;
insert into t1 select * from tmp;
--echo #
--echo # Update with EXISTS subquery over the updated table
--echo # in WHERE + non-sargable condition
--echo #
analyze table t1 persistent for all;
let $c = exists (select 'X' from t1 a where a.c2 = t1.c2) and c2 >= 3;
let $q = update t1 set c1=c1+10 where $c;
eval explain select * from t1 where $c;
eval explain $q;
--enable_info ONCE
eval $q;
select concat(old_c1,'->',c1),c3,
case when c1 != old_c1 then '*' else ' ' end "Changed" from t1;
truncate table t1;
insert into t1 select * from tmp;
--echo #
--echo # Update with order by
--echo #
analyze table t1 persistent for all;
let $c = exists (select 'X' from t1 a where a.c2 = t1.c2)
and c2 >= 3 order by c2;
let $q = update t1 set c1=c1+10 where $c;
eval explain select * from t1 where $c;
eval explain $q;
--enable_info ONCE
eval $q;
select concat(old_c1,'->',c1),c3,
case when c1 != old_c1 then '*' else ' ' end "Changed" from t1;
truncate table t1;
insert into t1 select * from tmp;
--echo #
--echo # Update with a reference to view in subquery
--echo # in settable value
--echo #
analyze table t1 persistent for all;
let $q = update t1 set c1=c1 +(select max(a.c2) from v1 a
where a.c1 = t1.c1);
eval explain select * from t1;
eval explain $q;
--enable_info ONCE
eval $q;
select concat(old_c1,'->',c1),c3,
case when c1 != old_c1 then '*' else ' ' end "Changed" from t1;
truncate table t1;
insert into t1 select * from tmp;
--echo #
--echo # Update view
--echo #
analyze table t1 persistent for all;
let $q = update v1 set c1=c1 + (select max(a.c2) from t1 a
where a.c1 = v1.c1) +10 where c3 > 3;
eval explain select * from v1;
eval explain $q;
--enable_info ONCE
eval $q;
select concat(old_c1,'->',c1),c3,
case when c1 != old_c1 then '*' else ' ' end "Changed" from t1;
truncate table t1;
insert into t1 select * from tmp;
--echo #
--echo # Update view with reference to the same view in subquery
--echo #
analyze table t1 persistent for all;
let $c = c1 <2
and exists (select 'X' from v1 a where a.c1 = v1.c1);
let $q = update v1 set c1=c1 + 1 where $c;
eval explain select * from v1 where $c;
eval explain $q;
--enable_info ONCE
eval $q;
select concat(old_c1,'->',c1),c3,
case when c1 != old_c1 then '*' else ' ' end "Changed" from t1;
truncate table t1;
insert into t1 select * from tmp;
--echo #
--echo # Update view with EXISTS and reference to the same view in subquery
--echo #
analyze table t1 persistent for all;
let $c = c1 <10 and exists (select 'X' from v1 a where a.c2 = v1.c2);
let $q = update v1
set c1=(select max(a.c1)+10 from v1 a where a.c1 = v1.c1)
where $c;
eval explain select * from v1 where $c;
eval explain $q;
--enable_info ONCE
eval $q;
select concat(old_c1,'->',c1),c3,
case when c1 != old_c1 then '*' else ' ' end "Changed" from t1;
truncate table t1;
insert into t1 select * from tmp;
--echo #
--echo # Update with IN predicand over the updated table in WHERE
--echo #
analyze table t1 persistent for all;
let $c = c2 in (select distinct a.c2 from t1 a where t1.c1=a.c1);
let $q = update t1 set c3=c3+110 where $c;
eval explain select * from t1 where $c;
eval explain $q;
--enable_info ONCE
eval $q;
--sorted_result
select c3 from t1;
truncate table t1;
insert into t1 select * from tmp;
--echo #
--echo # Update with a limit
--echo #
analyze table t1 persistent for all;
let $q = update t1
set c1=(select a.c3 from t1 a where a.c3 = t1.c3) limit 2;
eval explain select * from t1 limit 2;
eval explain $q;
--enable_info ONCE
eval $q;
select concat(old_c1,'->',c1),c3,
case when c1 != old_c1 then '*' else ' ' end "Changed" from t1;
truncate table t1;
insert into t1 select * from tmp;
--echo #
--echo # Update with a limit and an order by
--echo #
analyze table t1 persistent for all;
let $q=update t1
set c1=(select a.c3 from t1 a where a.c3 = t1.c3)
order by c3 desc limit 2;
eval explain select * from t1 order by c3 desc limit 2;
eval explain $q;
--enable_info ONCE
eval $q;
select concat(old_c1,'->',c1),c3,
case when c1 != old_c1 then '*' else ' ' end "Changed" from t1;
truncate table t1;
insert into t1 select * from tmp;
--echo #
--echo # Test on dynamic columns (blob)
--echo #
create table assets (
item_name varchar(32) primary key, -- A common attribute for all items
dynamic_cols blob -- Dynamic columns will be stored here
);
INSERT INTO assets VALUES ('MariaDB T-shirt',
COLUMN_CREATE('color', 'blue', 'size', 'XL'));
INSERT INTO assets VALUES ('Thinkpad Laptop',
COLUMN_CREATE('color', 'black', 'price', 500));
SELECT item_name, COLUMN_GET(dynamic_cols, 'color' as char) AS color
FROM assets;
UPDATE assets
SET dynamic_cols=COLUMN_ADD(dynamic_cols, 'warranty', '3 years')
WHERE item_name='Thinkpad Laptop';
SELECT item_name,
COLUMN_GET(dynamic_cols, 'warranty' as char) AS color
FROM assets;
UPDATE assets
SET dynamic_cols=COLUMN_ADD(dynamic_cols, 'warranty', '4 years')
WHERE item_name in
(select b.item_name from assets b
where COLUMN_GET(b.dynamic_cols, 'color' as char) ='black');
SELECT item_name,
COLUMN_GET(dynamic_cols, 'warranty' as char) AS color
FROM assets;
UPDATE assets SET dynamic_cols=COLUMN_ADD(dynamic_cols, 'warranty',
(select COLUMN_GET(b.dynamic_cols, 'color' as char)
from assets b
where assets.item_name = item_name));
SELECT item_name,
COLUMN_GET(dynamic_cols, 'warranty' as char) AS color
FROM assets;
drop table assets;
--echo #
--echo # Test on fulltext columns
--echo #
CREATE TABLE ft2(copy TEXT,FULLTEXT(copy));
INSERT INTO ft2(copy) VALUES
('MySQL vs MariaDB database'),
('Oracle vs MariaDB database'),
('PostgreSQL vs MariaDB database'),
('MariaDB overview'),
('Foreign keys'),
('Primary keys'),
('Indexes'),
('Transactions'),
('Triggers');
SELECT * FROM ft2 WHERE MATCH(copy) AGAINST('database');
update ft2 set copy = (select max(concat('mykeyword ',substr(b.copy,1,5)))
from ft2 b WHERE MATCH(b.copy) AGAINST('database'))
where MATCH(copy) AGAINST('keys');
SELECT * FROM ft2 WHERE MATCH(copy) AGAINST('mykeyword');
drop table ft2;
......@@ -3419,4 +3419,834 @@ o_orderkey o_totalprice
4903 34363.63
5607 24660.06
drop table t;
CREATE TABLE partsupp_small (
ps_partkey int(11) NOT NULL DEFAULT '0',
ps_suppkey int(11) NOT NULL DEFAULT '0',
ps_availqty int(11) DEFAULT NULL,
ps_supplycost double DEFAULT NULL,
ps_comment varchar(199) DEFAULT NULL,
PRIMARY KEY (ps_partkey,ps_suppkey),
KEY i_ps_partkey (ps_partkey),
KEY i_ps_suppkey (ps_suppkey)
);
create index i_ps_sup_part on partsupp_small(ps_suppkey, ps_partkey);
insert into partsupp_small select * from partsupp where ps_partkey <50;
analyze table partsupp_small persistent for all;
Table Op Msg_type Msg_text
dbt3_s001.partsupp_small analyze status Engine-independent statistics collected
dbt3_s001.partsupp_small analyze status OK
# LooseScan
# =========
explain
select count(*) from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY partsupp_small index PRIMARY,i_ps_partkey,i_ps_suppkey,i_ps_sup_part PRIMARY 8 NULL 176 Using where; Using index; LooseScan
1 PRIMARY lineitem ref i_l_suppkey_partkey,i_l_partkey i_l_partkey 5 dbt3_s001.partsupp_small.ps_partkey 30 Using index
explain format=json
select count(*) from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost": 0.222764041,
"nested_loop": [
{
"table": {
"table_name": "partsupp_small",
"access_type": "index",
"possible_keys": [
"PRIMARY",
"i_ps_partkey",
"i_ps_suppkey",
"i_ps_sup_part"
],
"key": "PRIMARY",
"key_length": "8",
"used_key_parts": ["ps_partkey", "ps_suppkey"],
"loops": 1,
"rows": 176,
"cost": 0.019403477,
"filtered": 23.86363602,
"attached_condition": "partsupp_small.ps_suppkey in (1,2,3)",
"using_index": true,
"loose_scan": true
}
},
{
"table": {
"table_name": "lineitem",
"access_type": "ref",
"possible_keys": ["i_l_suppkey_partkey", "i_l_partkey"],
"key": "i_l_partkey",
"key_length": "5",
"used_key_parts": ["l_partkey"],
"ref": ["dbt3_s001.partsupp_small.ps_partkey"],
"loops": 42,
"rows": 30,
"cost": 0.203360564,
"filtered": 2.380952358,
"using_index": true
}
}
]
}
}
explain
select l_partkey from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY partsupp_small index PRIMARY,i_ps_partkey,i_ps_suppkey,i_ps_sup_part PRIMARY 8 NULL 176 Using where; Using index; LooseScan
1 PRIMARY lineitem ref i_l_suppkey_partkey,i_l_partkey i_l_partkey 5 dbt3_s001.partsupp_small.ps_partkey 30 Using index
explain format=json
select l_partkey from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost": 0.222764041,
"nested_loop": [
{
"table": {
"table_name": "partsupp_small",
"access_type": "index",
"possible_keys": [
"PRIMARY",
"i_ps_partkey",
"i_ps_suppkey",
"i_ps_sup_part"
],
"key": "PRIMARY",
"key_length": "8",
"used_key_parts": ["ps_partkey", "ps_suppkey"],
"loops": 1,
"rows": 176,
"cost": 0.019403477,
"filtered": 23.86363602,
"attached_condition": "partsupp_small.ps_suppkey in (1,2,3)",
"using_index": true,
"loose_scan": true
}
},
{
"table": {
"table_name": "lineitem",
"access_type": "ref",
"possible_keys": ["i_l_suppkey_partkey", "i_l_partkey"],
"key": "i_l_partkey",
"key_length": "5",
"used_key_parts": ["l_partkey"],
"ref": ["dbt3_s001.partsupp_small.ps_partkey"],
"loops": 42,
"rows": 30,
"cost": 0.203360564,
"filtered": 2.380952358,
"using_index": true
}
}
]
}
}
select count(*) from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
count(*)
1175
create table t as
select * from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
explain
delete from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY partsupp_small index PRIMARY,i_ps_partkey,i_ps_suppkey,i_ps_sup_part PRIMARY 8 NULL 176 Using where; Using index; LooseScan
1 PRIMARY lineitem ref i_l_suppkey_partkey,i_l_partkey i_l_partkey 5 dbt3_s001.partsupp_small.ps_partkey 30
explain format=json
delete from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost": 0.222764041,
"nested_loop": [
{
"table": {
"table_name": "partsupp_small",
"access_type": "index",
"possible_keys": [
"PRIMARY",
"i_ps_partkey",
"i_ps_suppkey",
"i_ps_sup_part"
],
"key": "PRIMARY",
"key_length": "8",
"used_key_parts": ["ps_partkey", "ps_suppkey"],
"loops": 1,
"rows": 176,
"cost": 0.019403477,
"filtered": 23.86363602,
"attached_condition": "partsupp_small.ps_suppkey in (1,2,3)",
"using_index": true,
"loose_scan": true
}
},
{
"table": {
"table_name": "lineitem",
"access_type": "ref",
"possible_keys": ["i_l_suppkey_partkey", "i_l_partkey"],
"key": "i_l_partkey",
"key_length": "5",
"used_key_parts": ["l_partkey"],
"ref": ["dbt3_s001.partsupp_small.ps_partkey"],
"loops": 42,
"rows": 30,
"cost": 0.203360564,
"filtered": 2.380952358
}
}
]
}
}
delete from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
select count(*) from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
count(*)
0
insert into lineitem select * from t;
select count(*) from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
count(*)
1175
drop table t;
# LooseScan PS
# ============
prepare stmt from "
delete from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
";
select count(*) from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
count(*)
1175
create table t as
select * from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
execute stmt;
select count(*) from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
count(*)
0
insert into lineitem select * from t;
select count(*) from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
count(*)
1175
create table r as
select * from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
execute stmt;
select count(*) from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
count(*)
0
insert into lineitem select * from r;
select count(*) from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
count(*)
1175
drop tables r, t;
deallocate prepare stmt;
# LooseScan SP
# ============
create procedure p()
delete from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
select count(*) from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
count(*)
1175
create table t as
select * from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
call p();
select count(*) from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
count(*)
0
insert into lineitem select * from t;
select count(*) from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
count(*)
1175
create table r as
select * from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
call p();
select count(*) from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
count(*)
0
insert into lineitem select * from r;
select count(*) from lineitem where l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
count(*)
1175
drop tables r, t;
drop procedure p;
# DuplicateWeedout
# ================
set @tmp_optimizer_switch= @@optimizer_switch;
set optimizer_switch='materialization=off';
analyze table lineitem;
Table Op Msg_type Msg_text
dbt3_s001.lineitem analyze status Engine-independent statistics collected
dbt3_s001.lineitem analyze status OK
analyze table orders;
Table Op Msg_type Msg_text
dbt3_s001.orders analyze status Engine-independent statistics collected
dbt3_s001.orders analyze status OK
explain
select count(*) from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY supplier range PRIMARY PRIMARY 4 NULL 1 Using where; Using index; Start temporary
1 PRIMARY partsupp_small ref PRIMARY,i_ps_partkey,i_ps_suppkey,i_ps_sup_part i_ps_sup_part 4 dbt3_s001.supplier.s_suppkey 17 Using where; Using index
1 PRIMARY lineitem ref i_l_suppkey_partkey,i_l_partkey i_l_suppkey_partkey 5 dbt3_s001.partsupp_small.ps_partkey 30 Using index
1 PRIMARY lineitem ref i_l_suppkey_partkey,i_l_partkey i_l_partkey 5 dbt3_s001.partsupp_small.ps_partkey 30 Using index; End temporary
explain format=json
select count(*) from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost": 4.129940741,
"nested_loop": [
{
"duplicates_removal": [
{
"table": {
"table_name": "supplier",
"access_type": "range",
"possible_keys": ["PRIMARY"],
"key": "PRIMARY",
"key_length": "4",
"used_key_parts": ["s_suppkey"],
"loops": 1,
"rows": 1,
"cost": 0.001478954,
"filtered": 100,
"attached_condition": "supplier.s_suppkey < 2",
"using_index": true
}
},
{
"table": {
"table_name": "partsupp_small",
"access_type": "ref",
"possible_keys": [
"PRIMARY",
"i_ps_partkey",
"i_ps_suppkey",
"i_ps_sup_part"
],
"key": "i_ps_sup_part",
"key_length": "4",
"used_key_parts": ["ps_suppkey"],
"ref": ["dbt3_s001.supplier.s_suppkey"],
"loops": 1,
"rows": 17,
"cost": 0.003160332,
"filtered": 79.54545593,
"attached_condition": "partsupp_small.ps_partkey is not null",
"using_index": true
}
},
{
"table": {
"table_name": "lineitem",
"access_type": "ref",
"possible_keys": ["i_l_suppkey_partkey", "i_l_partkey"],
"key": "i_l_suppkey_partkey",
"key_length": "5",
"used_key_parts": ["l_partkey"],
"ref": ["dbt3_s001.partsupp_small.ps_partkey"],
"loops": 14,
"rows": 30,
"cost": 0.069152188,
"filtered": 100,
"using_index": true
}
},
{
"table": {
"table_name": "lineitem",
"access_type": "ref",
"possible_keys": ["i_l_suppkey_partkey", "i_l_partkey"],
"key": "i_l_partkey",
"key_length": "5",
"used_key_parts": ["l_partkey"],
"ref": ["dbt3_s001.partsupp_small.ps_partkey"],
"loops": 420.35,
"rows": 30,
"cost": 1.994712365,
"filtered": 0.237896994,
"using_index": true
}
}
]
}
]
}
}
explain
select l_partkey from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY supplier range PRIMARY PRIMARY 4 NULL 1 Using where; Using index; Start temporary
1 PRIMARY partsupp_small ref PRIMARY,i_ps_partkey,i_ps_suppkey,i_ps_sup_part i_ps_sup_part 4 dbt3_s001.supplier.s_suppkey 17 Using where; Using index
1 PRIMARY lineitem ref i_l_suppkey_partkey,i_l_partkey i_l_suppkey_partkey 5 dbt3_s001.partsupp_small.ps_partkey 30 Using index
1 PRIMARY lineitem ref i_l_suppkey_partkey,i_l_partkey i_l_partkey 5 dbt3_s001.partsupp_small.ps_partkey 30 Using index; End temporary
explain format=json
select l_partkey from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost": 4.129940741,
"nested_loop": [
{
"duplicates_removal": [
{
"table": {
"table_name": "supplier",
"access_type": "range",
"possible_keys": ["PRIMARY"],
"key": "PRIMARY",
"key_length": "4",
"used_key_parts": ["s_suppkey"],
"loops": 1,
"rows": 1,
"cost": 0.001478954,
"filtered": 100,
"attached_condition": "supplier.s_suppkey < 2",
"using_index": true
}
},
{
"table": {
"table_name": "partsupp_small",
"access_type": "ref",
"possible_keys": [
"PRIMARY",
"i_ps_partkey",
"i_ps_suppkey",
"i_ps_sup_part"
],
"key": "i_ps_sup_part",
"key_length": "4",
"used_key_parts": ["ps_suppkey"],
"ref": ["dbt3_s001.supplier.s_suppkey"],
"loops": 1,
"rows": 17,
"cost": 0.003160332,
"filtered": 79.54545593,
"attached_condition": "partsupp_small.ps_partkey is not null",
"using_index": true
}
},
{
"table": {
"table_name": "lineitem",
"access_type": "ref",
"possible_keys": ["i_l_suppkey_partkey", "i_l_partkey"],
"key": "i_l_suppkey_partkey",
"key_length": "5",
"used_key_parts": ["l_partkey"],
"ref": ["dbt3_s001.partsupp_small.ps_partkey"],
"loops": 14,
"rows": 30,
"cost": 0.069152188,
"filtered": 100,
"using_index": true
}
},
{
"table": {
"table_name": "lineitem",
"access_type": "ref",
"possible_keys": ["i_l_suppkey_partkey", "i_l_partkey"],
"key": "i_l_partkey",
"key_length": "5",
"used_key_parts": ["l_partkey"],
"ref": ["dbt3_s001.partsupp_small.ps_partkey"],
"loops": 420.35,
"rows": 30,
"cost": 1.994712365,
"filtered": 0.237896994,
"using_index": true
}
}
]
}
]
}
}
select count(*) from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
count(*)
471
create table t as
select * from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
explain
delete from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY supplier range PRIMARY PRIMARY 4 NULL 1 Using where; Using index; Start temporary
1 PRIMARY partsupp_small ref PRIMARY,i_ps_partkey,i_ps_suppkey,i_ps_sup_part i_ps_sup_part 4 dbt3_s001.supplier.s_suppkey 17 Using where; Using index
1 PRIMARY lineitem ref i_l_suppkey_partkey,i_l_partkey i_l_suppkey_partkey 5 dbt3_s001.partsupp_small.ps_partkey 30
1 PRIMARY lineitem ref i_l_suppkey_partkey,i_l_partkey i_l_partkey 5 dbt3_s001.partsupp_small.ps_partkey 30 Using index; End temporary
explain format=json
delete from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost": 4.129940741,
"nested_loop": [
{
"duplicates_removal": [
{
"table": {
"table_name": "supplier",
"access_type": "range",
"possible_keys": ["PRIMARY"],
"key": "PRIMARY",
"key_length": "4",
"used_key_parts": ["s_suppkey"],
"loops": 1,
"rows": 1,
"cost": 0.001478954,
"filtered": 100,
"attached_condition": "supplier.s_suppkey < 2",
"using_index": true
}
},
{
"table": {
"table_name": "partsupp_small",
"access_type": "ref",
"possible_keys": [
"PRIMARY",
"i_ps_partkey",
"i_ps_suppkey",
"i_ps_sup_part"
],
"key": "i_ps_sup_part",
"key_length": "4",
"used_key_parts": ["ps_suppkey"],
"ref": ["dbt3_s001.supplier.s_suppkey"],
"loops": 1,
"rows": 17,
"cost": 0.003160332,
"filtered": 79.54545593,
"attached_condition": "partsupp_small.ps_partkey is not null",
"using_index": true
}
},
{
"table": {
"table_name": "lineitem",
"access_type": "ref",
"possible_keys": ["i_l_suppkey_partkey", "i_l_partkey"],
"key": "i_l_suppkey_partkey",
"key_length": "5",
"used_key_parts": ["l_partkey"],
"ref": ["dbt3_s001.partsupp_small.ps_partkey"],
"loops": 14,
"rows": 30,
"cost": 0.069152188,
"filtered": 100
}
},
{
"table": {
"table_name": "lineitem",
"access_type": "ref",
"possible_keys": ["i_l_suppkey_partkey", "i_l_partkey"],
"key": "i_l_partkey",
"key_length": "5",
"used_key_parts": ["l_partkey"],
"ref": ["dbt3_s001.partsupp_small.ps_partkey"],
"loops": 420.35,
"rows": 30,
"cost": 1.994712365,
"filtered": 0.237896994,
"using_index": true
}
}
]
}
]
}
}
delete from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
select count(*) from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
count(*)
0
insert into lineitem select * from t;
select count(*) from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
count(*)
471
drop table t;
# DuplicateWeedout PS
# ===================
prepare stmt from "
delete from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
";
select count(*) from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
count(*)
471
create table t as
select * from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
execute stmt;
select count(*) from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
count(*)
0
insert into lineitem select * from t;
select count(*) from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
count(*)
471
create table r as
select * from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
execute stmt;
select count(*) from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
count(*)
0
insert into lineitem select * from r;
select count(*) from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
count(*)
471
drop tables r, t;
deallocate prepare stmt;
# DuplicateWeedout SP
# ===================
create procedure p()
delete from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
select count(*) from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
count(*)
471
create table t as
select * from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
call p();
select count(*) from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
count(*)
0
insert into lineitem select * from t;
select count(*) from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
count(*)
471
create table r as
select * from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
call p();
select count(*) from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
count(*)
0
insert into lineitem select * from r;
select count(*) from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
count(*)
471
drop tables r, t;
drop procedure p;
set @@optimizer_switch=@tmp_optimizer_switch;
drop table partsupp_small;
DROP DATABASE dbt3_s001;
......@@ -822,4 +822,248 @@ eval
select o_orderkey, o_totalprice from orders where $c11;
drop table t;
CREATE TABLE partsupp_small (
ps_partkey int(11) NOT NULL DEFAULT '0',
ps_suppkey int(11) NOT NULL DEFAULT '0',
ps_availqty int(11) DEFAULT NULL,
ps_supplycost double DEFAULT NULL,
ps_comment varchar(199) DEFAULT NULL,
PRIMARY KEY (ps_partkey,ps_suppkey),
KEY i_ps_partkey (ps_partkey),
KEY i_ps_suppkey (ps_suppkey)
);
create index i_ps_sup_part on partsupp_small(ps_suppkey, ps_partkey);
insert into partsupp_small select * from partsupp where ps_partkey <50;
analyze table partsupp_small persistent for all;
--echo # LooseScan
--echo # =========
let $c12 = l_partkey in
(select ps_partkey from partsupp_small
where ps_suppkey in (1,2,3));
eval
explain
select count(*) from lineitem where $c12;
eval
explain format=json
select count(*) from lineitem where $c12;
eval
explain
select l_partkey from lineitem where $c12;
eval
explain format=json
select l_partkey from lineitem where $c12;
eval
select count(*) from lineitem where $c12;
eval
create table t as
select * from lineitem where $c12;
eval
explain
delete from lineitem where $c12;
eval
explain format=json
delete from lineitem where $c12;
eval
delete from lineitem where $c12;
eval
select count(*) from lineitem where $c12;
insert into lineitem select * from t;
eval
select count(*) from lineitem where $c12;
drop table t;
--echo # LooseScan PS
--echo # ============
eval
prepare stmt from "
delete from lineitem where $c12;
";
eval
select count(*) from lineitem where $c12;
eval
create table t as
select * from lineitem where $c12;
execute stmt;
eval
select count(*) from lineitem where $c12;
insert into lineitem select * from t;
eval
select count(*) from lineitem where $c12;
eval
create table r as
select * from lineitem where $c12;
execute stmt;
eval
select count(*) from lineitem where $c12;
insert into lineitem select * from r;
eval
select count(*) from lineitem where $c12;
drop tables r, t;
deallocate prepare stmt;
--echo # LooseScan SP
--echo # ============
eval
create procedure p()
delete from lineitem where $c12;
eval
select count(*) from lineitem where $c12;
eval
create table t as
select * from lineitem where $c12;
call p();
eval
select count(*) from lineitem where $c12;
insert into lineitem select * from t;
eval
select count(*) from lineitem where $c12;
eval
create table r as
select * from lineitem where $c12;
call p();
eval
select count(*) from lineitem where $c12;
insert into lineitem select * from r;
eval
select count(*) from lineitem where $c12;
drop tables r, t;
drop procedure p;
--echo # DuplicateWeedout
--echo # ================
set @tmp_optimizer_switch= @@optimizer_switch;
set optimizer_switch='materialization=off';
analyze table lineitem;
analyze table orders;
let $c13 = l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
eval
explain
select count(*) from lineitem where $c13;
eval
explain format=json
select count(*) from lineitem where $c13;
eval
explain
select l_partkey from lineitem where $c13;
eval
explain format=json
select l_partkey from lineitem where $c13;
eval
select count(*) from lineitem where $c13;
eval
create table t as
select * from lineitem where $c13;
eval
explain
delete from lineitem where $c13;
eval
explain format=json
delete from lineitem where $c13;
eval
delete from lineitem where $c13;
eval
select count(*) from lineitem where $c13;
insert into lineitem select * from t;
eval
select count(*) from lineitem where $c13;
drop table t;
--echo # DuplicateWeedout PS
--echo # ===================
eval
prepare stmt from "
delete from lineitem where $c13;
";
eval
select count(*) from lineitem where $c13;
eval
create table t as
select * from lineitem where $c13;
execute stmt;
eval
select count(*) from lineitem where $c13;
insert into lineitem select * from t;
eval
select count(*) from lineitem where $c13;
eval
create table r as
select * from lineitem where $c13;
execute stmt;
eval
select count(*) from lineitem where $c13;
insert into lineitem select * from r;
eval
select count(*) from lineitem where $c13;
drop tables r, t;
deallocate prepare stmt;
--echo # DuplicateWeedout SP
--echo # ===================
eval
create procedure p()
delete from lineitem where $c13;
eval
select count(*) from lineitem where $c13;
eval
create table t as
select * from lineitem where $c13;
call p();
eval
select count(*) from lineitem where $c13;
insert into lineitem select * from t;
eval
select count(*) from lineitem where $c13;
eval
create table r as
select * from lineitem where $c13;
call p();
eval
select count(*) from lineitem where $c13;
insert into lineitem select * from r;
eval
select count(*) from lineitem where $c13;
drop tables r, t;
drop procedure p;
set @@optimizer_switch=@tmp_optimizer_switch;
drop table partsupp_small;
DROP DATABASE dbt3_s001;
This source diff could not be displayed because it is too large. You can view the blob instead.
--source include/have_innodb.inc
set @save_default_engine=@@default_storage_engine;
--echo #######################################
--echo # #
--echo # Engine InnoDB #
--echo # #
--echo #######################################
set global innodb_stats_persistent=1;
set default_storage_engine=InnoDB;
--source include/delete_use_source_innodb.inc
--echo #######################################
--echo # #
--echo # Engine Aria #
--echo # #
--echo #######################################
set default_storage_engine=Aria;
--source include/delete_use_source.inc
--echo #######################################
--echo # #
--echo # Engine MyISAM #
--echo # #
--echo #######################################
set default_storage_engine=MyISAM;
--source include/delete_use_source.inc
--echo #######################################
--echo # #
--echo # Engine MEMORY #
--echo # #
--echo #######################################
set default_storage_engine=MEMORY;
--source include/delete_use_source_memory.inc
set @@default_storage_engine=@save_default_engine;
--echo #
--echo # End of 11.0 tests
--echo #
......@@ -3242,4 +3242,619 @@ o_orderkey o_totalprice
3139 40975.96
4903 34363.63
5607 24660.06
CREATE TABLE partsupp_small (
ps_partkey int(11) NOT NULL DEFAULT '0',
ps_suppkey int(11) NOT NULL DEFAULT '0',
ps_availqty int(11) DEFAULT NULL,
ps_supplycost double DEFAULT NULL,
ps_comment varchar(199) DEFAULT NULL,
PRIMARY KEY (ps_partkey,ps_suppkey),
KEY i_ps_partkey (ps_partkey),
KEY i_ps_suppkey (ps_suppkey)
);
create index i_ps_sup_part on partsupp_small(ps_suppkey, ps_partkey);
insert into partsupp_small select * from partsupp where ps_partkey <50;
analyze table partsupp_small persistent for all;
Table Op Msg_type Msg_text
dbt3_s001.partsupp_small analyze status Engine-independent statistics collected
dbt3_s001.partsupp_small analyze status OK
# LooseScan
# =========
explain
select count(*) from lineitem where l_suppkey in
(select ps_suppkey from partsupp_small
where ps_partkey in (1,2,3));
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY partsupp_small index PRIMARY,i_ps_partkey,i_ps_suppkey,i_ps_sup_part i_ps_sup_part 8 NULL 176 Using where; Using index; LooseScan
1 PRIMARY lineitem ref i_l_suppkey i_l_suppkey 5 dbt3_s001.partsupp_small.ps_suppkey 600 Using index
explain format=json
select count(*) from lineitem where l_suppkey in
(select ps_suppkey from partsupp_small
where ps_partkey in (1,2,3));
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost": 0.776623555,
"nested_loop": [
{
"table": {
"table_name": "partsupp_small",
"access_type": "index",
"possible_keys": [
"PRIMARY",
"i_ps_partkey",
"i_ps_suppkey",
"i_ps_sup_part"
],
"key": "i_ps_sup_part",
"key_length": "8",
"used_key_parts": ["ps_suppkey", "ps_partkey"],
"loops": 1,
"rows": 176,
"cost": 0.019403477,
"filtered": 5.113636494,
"attached_condition": "partsupp_small.ps_partkey in (1,2,3)",
"using_index": true,
"loose_scan": true
}
},
{
"table": {
"table_name": "lineitem",
"access_type": "ref",
"possible_keys": ["i_l_suppkey"],
"key": "i_l_suppkey",
"key_length": "5",
"used_key_parts": ["l_suppkey"],
"ref": ["dbt3_s001.partsupp_small.ps_suppkey"],
"loops": 9,
"rows": 600,
"cost": 0.757220078,
"filtered": 11.11111069,
"using_index": true
}
}
]
}
}
select count(*) from lineitem where l_suppkey in
(select ps_suppkey from partsupp_small
where ps_partkey in (1,2,3));
count(*)
5373
select 5373 as count, 136458704.22 as old_sum;
count old_sum
5373 136458704.22
explain
update lineitem set l_extendedprice=l_extendedprice+10 where l_suppkey in
(select ps_suppkey from partsupp_small
where ps_partkey in (1,2,3));
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY lineitem ALL i_l_suppkey NULL NULL NULL 6005
1 PRIMARY <subquery2> eq_ref distinct_key distinct_key 4 func 1
2 MATERIALIZED partsupp_small range PRIMARY,i_ps_partkey,i_ps_suppkey,i_ps_sup_part PRIMARY 4 NULL 9 Using where; Using index
explain format=json
update lineitem set l_extendedprice=l_extendedprice+10 where l_suppkey in
(select ps_suppkey from partsupp_small
where ps_partkey in (1,2,3));
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost": 2.191459679,
"nested_loop": [
{
"table": {
"table_name": "lineitem",
"access_type": "ALL",
"possible_keys": ["i_l_suppkey"],
"loops": 1,
"rows": 6005,
"cost": 0.988432825,
"filtered": 100
}
},
{
"table": {
"table_name": "<subquery2>",
"access_type": "eq_ref",
"possible_keys": ["distinct_key"],
"key": "distinct_key",
"key_length": "4",
"used_key_parts": ["ps_suppkey"],
"ref": ["func"],
"rows": 1,
"filtered": 100,
"materialized": {
"unique": 1,
"query_block": {
"select_id": 2,
"nested_loop": [
{
"table": {
"table_name": "partsupp_small",
"access_type": "range",
"possible_keys": [
"PRIMARY",
"i_ps_partkey",
"i_ps_suppkey",
"i_ps_sup_part"
],
"key": "PRIMARY",
"key_length": "4",
"used_key_parts": ["ps_partkey"],
"loops": 1,
"rows": 9,
"cost": 0.003756598,
"filtered": 100,
"attached_condition": "partsupp_small.ps_partkey in (1,2,3)",
"using_index": true
}
}
]
}
}
}
}
]
}
}
update lineitem set l_extendedprice=l_extendedprice+10 where l_suppkey in
(select ps_suppkey from partsupp_small
where ps_partkey in (1,2,3));
select ROUND(sum(l_extendedprice),2), 5373 as count,
(136458704.22+10*5373) as 'old_sum+10*count'
from lineitem where l_suppkey in
(select ps_suppkey from partsupp_small
where ps_partkey in (1,2,3));
ROUND(sum(l_extendedprice),2) count old_sum+10*count
136512434.22 5373 136512434.22
update lineitem set l_extendedprice=l_extendedprice-10 where l_suppkey in
(select ps_suppkey from partsupp_small
where ps_partkey in (1,2,3));
select ROUND(sum(l_extendedprice),2), 5373 as count,
136458704.22 as old_sum from lineitem where l_suppkey in
(select ps_suppkey from partsupp_small
where ps_partkey in (1,2,3));
ROUND(sum(l_extendedprice),2) count old_sum
136458704.22 5373 136458704.22
# LooseScan PS
# ============
prepare stmt from "
update lineitem set l_extendedprice=l_extendedprice+? where l_suppkey in
(select ps_suppkey from partsupp_small
where ps_partkey in (1,2,3));
";
select 5373 as count, 136458704.22 as old_sum;
count old_sum
5373 136458704.22
set @a1=20;
execute stmt using @a1;
select ROUND(sum(l_extendedprice),2), 5373 as count,
(136458704.22+20*5373) as 'old_sum+20*count'
from lineitem where l_suppkey in
(select ps_suppkey from partsupp_small
where ps_partkey in (1,2,3));
ROUND(sum(l_extendedprice),2) count old_sum+20*count
136566164.22 5373 136566164.22
set @a2=10;
execute stmt using @a2;
select ROUND(sum(l_extendedprice),2), 5373 as count,
(136458704.22+30*5373) as 'old_sum+30*count'
from lineitem where l_suppkey in
(select ps_suppkey from partsupp_small
where ps_partkey in (1,2,3));
ROUND(sum(l_extendedprice),2) count old_sum+30*count
136619894.22 5373 136619894.22
execute stmt using -(@a1+@a2);
select ROUND(sum(l_extendedprice),2), 5373 as count,
136458704.22 as old_sum from lineitem where l_suppkey in
(select ps_suppkey from partsupp_small
where ps_partkey in (1,2,3));
ROUND(sum(l_extendedprice),2) count old_sum
136458704.22 5373 136458704.22
deallocate prepare stmt;
# LooseScan SP
# ============
create procedure p(d int)
update lineitem set l_extendedprice=l_extendedprice+d where l_suppkey in
(select ps_suppkey from partsupp_small
where ps_partkey in (1,2,3));
select 5373 as count, 136458704.22 as old_sum;
count old_sum
5373 136458704.22
call p(10);
select ROUND(sum(l_extendedprice),2), 5373 as count,
(136458704.22+10*5373) as 'old_sum+10*count'
from lineitem where l_suppkey in
(select ps_suppkey from partsupp_small
where ps_partkey in (1,2,3));
ROUND(sum(l_extendedprice),2) count old_sum+10*count
136512434.22 5373 136512434.22
call p(20);
select ROUND(sum(l_extendedprice),2), 5373 as count,
(136458704.22+30*5373) as 'old_sum+30*count'
from lineitem where l_suppkey in
(select ps_suppkey from partsupp_small
where ps_partkey in (1,2,3));
ROUND(sum(l_extendedprice),2) count old_sum+30*count
136619894.22 5373 136619894.22
call p(-(10+20));
select ROUND(sum(l_extendedprice),2), 5373 as count,
136458704.22 as old_sum from lineitem where l_suppkey in
(select ps_suppkey from partsupp_small
where ps_partkey in (1,2,3));
ROUND(sum(l_extendedprice),2) count old_sum
136458704.22 5373 136458704.22
drop procedure p;
# DuplicateWeedout
# ================
set @tmp_optimizer_switch= @@optimizer_switch;
set optimizer_switch='materialization=off';
analyze table lineitem;
Table Op Msg_type Msg_text
dbt3_s001.lineitem analyze status Engine-independent statistics collected
dbt3_s001.lineitem analyze status OK
analyze table orders;
Table Op Msg_type Msg_text
dbt3_s001.orders analyze status Engine-independent statistics collected
dbt3_s001.orders analyze status OK
explain
select count(*) from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY supplier range PRIMARY PRIMARY 4 NULL 1 Using where; Using index; Start temporary
1 PRIMARY partsupp_small ref PRIMARY,i_ps_partkey,i_ps_suppkey,i_ps_sup_part i_ps_sup_part 4 dbt3_s001.supplier.s_suppkey 17 Using where; Using index
1 PRIMARY lineitem ref i_l_suppkey_partkey,i_l_partkey i_l_suppkey_partkey 5 dbt3_s001.partsupp_small.ps_partkey 30 Using index
1 PRIMARY lineitem ref i_l_suppkey_partkey,i_l_partkey i_l_partkey 5 dbt3_s001.partsupp_small.ps_partkey 30 Using index; End temporary
explain format=json
select count(*) from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost": 4.129940741,
"nested_loop": [
{
"duplicates_removal": [
{
"table": {
"table_name": "supplier",
"access_type": "range",
"possible_keys": ["PRIMARY"],
"key": "PRIMARY",
"key_length": "4",
"used_key_parts": ["s_suppkey"],
"loops": 1,
"rows": 1,
"cost": 0.001478954,
"filtered": 100,
"attached_condition": "supplier.s_suppkey < 2",
"using_index": true
}
},
{
"table": {
"table_name": "partsupp_small",
"access_type": "ref",
"possible_keys": [
"PRIMARY",
"i_ps_partkey",
"i_ps_suppkey",
"i_ps_sup_part"
],
"key": "i_ps_sup_part",
"key_length": "4",
"used_key_parts": ["ps_suppkey"],
"ref": ["dbt3_s001.supplier.s_suppkey"],
"loops": 1,
"rows": 17,
"cost": 0.003160332,
"filtered": 79.54545593,
"attached_condition": "partsupp_small.ps_partkey is not null",
"using_index": true
}
},
{
"table": {
"table_name": "lineitem",
"access_type": "ref",
"possible_keys": ["i_l_suppkey_partkey", "i_l_partkey"],
"key": "i_l_suppkey_partkey",
"key_length": "5",
"used_key_parts": ["l_partkey"],
"ref": ["dbt3_s001.partsupp_small.ps_partkey"],
"loops": 14,
"rows": 30,
"cost": 0.069152188,
"filtered": 100,
"using_index": true
}
},
{
"table": {
"table_name": "lineitem",
"access_type": "ref",
"possible_keys": ["i_l_suppkey_partkey", "i_l_partkey"],
"key": "i_l_partkey",
"key_length": "5",
"used_key_parts": ["l_partkey"],
"ref": ["dbt3_s001.partsupp_small.ps_partkey"],
"loops": 420.35,
"rows": 30,
"cost": 1.994712365,
"filtered": 0.237896994,
"using_index": true
}
}
]
}
]
}
}
select count(*) from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
count(*)
471
select 471 as count, 10751458.66 as old_sum;
count old_sum
471 10751458.66
explain
update lineitem set l_extendedprice=l_extendedprice+10 where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY supplier range PRIMARY PRIMARY 4 NULL 1 Using where; Using index; Start temporary
1 PRIMARY partsupp_small ref PRIMARY,i_ps_partkey,i_ps_suppkey,i_ps_sup_part i_ps_sup_part 4 dbt3_s001.supplier.s_suppkey 17 Using where; Using index
1 PRIMARY lineitem ref i_l_suppkey_partkey,i_l_partkey i_l_suppkey_partkey 5 dbt3_s001.partsupp_small.ps_partkey 30
1 PRIMARY lineitem ref i_l_suppkey_partkey,i_l_partkey i_l_partkey 5 dbt3_s001.partsupp_small.ps_partkey 30 Using index; End temporary
explain format=json
update lineitem set l_extendedprice=l_extendedprice+10 where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
EXPLAIN
{
"query_block": {
"select_id": 1,
"cost": 4.590092321,
"nested_loop": [
{
"duplicates_removal": [
{
"table": {
"table_name": "supplier",
"access_type": "range",
"possible_keys": ["PRIMARY"],
"key": "PRIMARY",
"key_length": "4",
"used_key_parts": ["s_suppkey"],
"loops": 1,
"rows": 1,
"cost": 0.001478954,
"filtered": 100,
"attached_condition": "supplier.s_suppkey < 2",
"using_index": true
}
},
{
"table": {
"table_name": "partsupp_small",
"access_type": "ref",
"possible_keys": [
"PRIMARY",
"i_ps_partkey",
"i_ps_suppkey",
"i_ps_sup_part"
],
"key": "i_ps_sup_part",
"key_length": "4",
"used_key_parts": ["ps_suppkey"],
"ref": ["dbt3_s001.supplier.s_suppkey"],
"loops": 1,
"rows": 17,
"cost": 0.003160332,
"filtered": 79.54545593,
"attached_condition": "partsupp_small.ps_partkey is not null",
"using_index": true
}
},
{
"table": {
"table_name": "lineitem",
"access_type": "ref",
"possible_keys": ["i_l_suppkey_partkey", "i_l_partkey"],
"key": "i_l_suppkey_partkey",
"key_length": "5",
"used_key_parts": ["l_partkey"],
"ref": ["dbt3_s001.partsupp_small.ps_partkey"],
"loops": 14,
"rows": 30,
"cost": 0.529303768,
"filtered": 100
}
},
{
"table": {
"table_name": "lineitem",
"access_type": "ref",
"possible_keys": ["i_l_suppkey_partkey", "i_l_partkey"],
"key": "i_l_partkey",
"key_length": "5",
"used_key_parts": ["l_partkey"],
"ref": ["dbt3_s001.partsupp_small.ps_partkey"],
"loops": 420.35,
"rows": 30,
"cost": 1.994712365,
"filtered": 0.237896994,
"using_index": true
}
}
]
}
]
}
}
update lineitem set l_extendedprice=l_extendedprice+10 where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
select ROUND(sum(l_extendedprice),2), 471 as count,
(10751458.66+10*471) as 'old_sum+10*count'
from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
ROUND(sum(l_extendedprice),2) count old_sum+10*count
10756168.66 471 10756168.66
update lineitem set l_extendedprice=l_extendedprice-10 where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
select ROUND(sum(l_extendedprice),2), 471 as count,
10751458.66 as old_sum from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
ROUND(sum(l_extendedprice),2) count old_sum
10751458.66 471 10751458.66
# DuplicateWeedout PS
# ===================
prepare stmt from "
update lineitem set l_extendedprice=l_extendedprice+? where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
";
select 471 as count, 10751458.66 as old_sum;
count old_sum
471 10751458.66
set @a1=20;
execute stmt using @a1;
select ROUND(sum(l_extendedprice),2), 471 as count,
(10751458.66+20*471) as 'old_sum+20*count'
from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
ROUND(sum(l_extendedprice),2) count old_sum+20*count
10760878.66 471 10760878.66
set @a2=10;
execute stmt using @a2;
select ROUND(sum(l_extendedprice),2), 471 as count,
(10751458.66+30*471) as 'old_sum+30*count'
from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
ROUND(sum(l_extendedprice),2) count old_sum+30*count
10765588.66 471 10765588.66
execute stmt using -(@a1+@a2);
select ROUND(sum(l_extendedprice),2), 471 as count,
10751458.66 as old_sum from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
ROUND(sum(l_extendedprice),2) count old_sum
10751458.66 471 10751458.66
deallocate prepare stmt;
# DuplicateWeedout SP
# ===================
create procedure p(d int)
update lineitem set l_extendedprice=l_extendedprice+d where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
select 471 as count, 10751458.66 as old_sum;
count old_sum
471 10751458.66
call p(10);
select ROUND(sum(l_extendedprice),2), 471 as count,
(10751458.66+10*471) as 'old_sum+10*count'
from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
ROUND(sum(l_extendedprice),2) count old_sum+10*count
10756168.66 471 10756168.66
call p(20);
select ROUND(sum(l_extendedprice),2), 471 as count,
(10751458.66+30*471) as 'old_sum+30*count'
from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
ROUND(sum(l_extendedprice),2) count old_sum+30*count
10765588.66 471 10765588.66
call p(-(10+20));
select ROUND(sum(l_extendedprice),2), 471 as count,
10751458.66 as old_sum from lineitem where l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
ROUND(sum(l_extendedprice),2) count old_sum
10751458.66 471 10751458.66
drop procedure p;
set @@optimizer_switch=@tmp_optimizer_switch;
drop table partsupp_small;
DROP DATABASE dbt3_s001;
......@@ -587,4 +587,246 @@ update orders set o_totalprice = o_totalprice+50 where $c11;
eval
select o_orderkey, o_totalprice from orders where $c11;
CREATE TABLE partsupp_small (
ps_partkey int(11) NOT NULL DEFAULT '0',
ps_suppkey int(11) NOT NULL DEFAULT '0',
ps_availqty int(11) DEFAULT NULL,
ps_supplycost double DEFAULT NULL,
ps_comment varchar(199) DEFAULT NULL,
PRIMARY KEY (ps_partkey,ps_suppkey),
KEY i_ps_partkey (ps_partkey),
KEY i_ps_suppkey (ps_suppkey)
);
create index i_ps_sup_part on partsupp_small(ps_suppkey, ps_partkey);
insert into partsupp_small select * from partsupp where ps_partkey <50;
analyze table partsupp_small persistent for all;
--echo # LooseScan
--echo # =========
let $c12 = l_suppkey in
(select ps_suppkey from partsupp_small
where ps_partkey in (1,2,3));
eval
explain
select count(*) from lineitem where $c12;
eval
explain format=json
select count(*) from lineitem where $c12;
eval
select count(*) from lineitem where $c12;
let $l_count =
query_get_value('select count(*) as a from lineitem where $c12;', a, 1);
let $l_old_sum =
query_get_value('select ROUND(sum(l_extendedprice),2) as a
from lineitem where $c12;', a, 1
);
eval select $l_count as count, $l_old_sum as old_sum;
eval
explain
update lineitem set l_extendedprice=l_extendedprice+10 where $c12;
eval
explain format=json
update lineitem set l_extendedprice=l_extendedprice+10 where $c12;
eval
update lineitem set l_extendedprice=l_extendedprice+10 where $c12;
eval
select ROUND(sum(l_extendedprice),2), $l_count as count,
($l_old_sum+10*$l_count) as 'old_sum+10*count'
from lineitem where $c12;
eval
update lineitem set l_extendedprice=l_extendedprice-10 where $c12;
eval
select ROUND(sum(l_extendedprice),2), $l_count as count,
$l_old_sum as old_sum from lineitem where $c12;
--echo # LooseScan PS
--echo # ============
eval
prepare stmt from "
update lineitem set l_extendedprice=l_extendedprice+? where $c12;
";
let $l_count = query_get_value('select count(*) as a
from lineitem where $c12;', a, 1 );
let $l_old_sum = query_get_value('select ROUND(sum(l_extendedprice),2) as a
from lineitem where $c12;', a, 1 );
eval select $l_count as count, $l_old_sum as old_sum;
eval
set @a1=20;
execute stmt using @a1;
eval
select ROUND(sum(l_extendedprice),2), $l_count as count,
($l_old_sum+20*$l_count) as 'old_sum+20*count'
from lineitem where $c12;
set @a2=10;
execute stmt using @a2;
eval
select ROUND(sum(l_extendedprice),2), $l_count as count,
($l_old_sum+30*$l_count) as 'old_sum+30*count'
from lineitem where $c12;
execute stmt using -(@a1+@a2);
eval
select ROUND(sum(l_extendedprice),2), $l_count as count,
$l_old_sum as old_sum from lineitem where $c12;
deallocate prepare stmt;
--echo # LooseScan SP
--echo # ============
eval
create procedure p(d int)
update lineitem set l_extendedprice=l_extendedprice+d where $c12;
let $l_count = query_get_value('select count(*) as a
from lineitem where $c12;', a, 1 );
let $l_old_sum = query_get_value('select ROUND(sum(l_extendedprice),2) as a
from lineitem where $c12;', a, 1 );
eval select $l_count as count, $l_old_sum as old_sum;
eval
call p(10);
eval
select ROUND(sum(l_extendedprice),2), $l_count as count,
($l_old_sum+10*$l_count) as 'old_sum+10*count'
from lineitem where $c12;
call p(20);
eval
select ROUND(sum(l_extendedprice),2), $l_count as count,
($l_old_sum+30*$l_count) as 'old_sum+30*count'
from lineitem where $c12;
call p(-(10+20));
eval
select ROUND(sum(l_extendedprice),2), $l_count as count,
$l_old_sum as old_sum from lineitem where $c12;
drop procedure p;
--echo # DuplicateWeedout
--echo # ================
set @tmp_optimizer_switch= @@optimizer_switch;
set optimizer_switch='materialization=off';
analyze table lineitem;
analyze table orders;
let $c13 = l_partkey in (
select ps_partkey
from partsupp_small join lineitem on ps_partkey=l_partkey
where ps_suppkey in (
select s_suppkey from supplier where s_suppkey < 2
)
);
eval
explain
select count(*) from lineitem where $c13;
eval
explain format=json
select count(*) from lineitem where $c13;
eval
select count(*) from lineitem where $c13;
let $l_count = query_get_value('select count(*) as a
from lineitem where $c13;', a, 1 );
let $l_old_sum = query_get_value('select ROUND(sum(l_extendedprice),2) as a
from lineitem where $c13;', a, 1 );
eval select $l_count as count, $l_old_sum as old_sum;
eval
explain
update lineitem set l_extendedprice=l_extendedprice+10 where $c13;
eval
explain format=json
update lineitem set l_extendedprice=l_extendedprice+10 where $c13;
eval
update lineitem set l_extendedprice=l_extendedprice+10 where $c13;
eval
select ROUND(sum(l_extendedprice),2), $l_count as count,
($l_old_sum+10*$l_count) as 'old_sum+10*count'
from lineitem where $c13;
eval
update lineitem set l_extendedprice=l_extendedprice-10 where $c13;
eval
select ROUND(sum(l_extendedprice),2), $l_count as count,
$l_old_sum as old_sum from lineitem where $c13;
--echo # DuplicateWeedout PS
--echo # ===================
eval
prepare stmt from "
update lineitem set l_extendedprice=l_extendedprice+? where $c13;
";
let $l_count =
query_get_value('select count(*) as a
from lineitem where $c13;', a, 1 );
let $l_old_sum =
query_get_value('select ROUND(sum(l_extendedprice),2) as a
from lineitem where $c13;', a, 1);
eval select $l_count as count, $l_old_sum as old_sum;
eval
set @a1=20;
execute stmt using @a1;
eval
select ROUND(sum(l_extendedprice),2), $l_count as count,
($l_old_sum+20*$l_count) as 'old_sum+20*count'
from lineitem where $c13;
set @a2=10;
execute stmt using @a2;
eval
select ROUND(sum(l_extendedprice),2), $l_count as count,
($l_old_sum+30*$l_count) as 'old_sum+30*count'
from lineitem where $c13;
execute stmt using -(@a1+@a2);
eval
select ROUND(sum(l_extendedprice),2), $l_count as count,
$l_old_sum as old_sum from lineitem where $c13;
deallocate prepare stmt;
--echo # DuplicateWeedout SP
--echo # ===================
eval
create procedure p(d int)
update lineitem set l_extendedprice=l_extendedprice+d where $c13;
let $l_count = query_get_value('select count(*) as a
from lineitem where $c13;', a, 1 );
let $l_old_sum = query_get_value('select ROUND(sum(l_extendedprice),2) as a
from lineitem where $c13;', a, 1 );
eval select $l_count as count, $l_old_sum as old_sum;
eval
call p(10);
eval
select ROUND(sum(l_extendedprice),2), $l_count as count,
($l_old_sum+10*$l_count) as 'old_sum+10*count'
from lineitem where $c13;
call p(20);
eval
select ROUND(sum(l_extendedprice),2), $l_count as count,
($l_old_sum+30*$l_count) as 'old_sum+30*count'
from lineitem where $c13;
call p(-(10+20));
eval
select ROUND(sum(l_extendedprice),2), $l_count as count,
$l_old_sum as old_sum from lineitem where $c13;
drop procedure p;
set @@optimizer_switch=@tmp_optimizer_switch;
drop table partsupp_small;
DROP DATABASE dbt3_s001;
This source diff could not be displayed because it is too large. You can view the blob instead.
......@@ -2,221 +2,55 @@
--source include/have_innodb.inc
--source include/no_valgrind_without_big.inc
create table t1 (old_c1 integer, old_c2 integer,c1 integer, c2 integer, c3 integer) engine=InnoDB STATS_PERSISTENT=0;
create view v1 as select * from t1 where c2=2;
delimiter /;
create trigger trg_t1 before update on t1 for each row
begin
set new.old_c1=old.c1;
set new.old_c2=old.c2;
end;
/
delimiter ;/
insert into t1(c1,c2,c3) values (1,1,1);
insert into t1(c1,c2,c3) values (1,2,2);
insert into t1(c1,c2,c3) values (1,3,3);
insert into t1(c1,c2,c3) values (2,1,4);
insert into t1(c1,c2,c3) values (2,2,5);
insert into t1(c1,c2,c3) values (2,3,6);
insert into t1(c1,c2,c3) values (2,4,7);
insert into t1(c1,c2,c3) values (2,5,8);
commit;
select * from t1;
--echo Test without any index
set @save_default_engine=@@default_storage_engine;
--echo #######################################
--echo # #
--echo # Engine InnoDB #
--echo # #
--echo #######################################
set global innodb_stats_persistent=1;
set default_storage_engine=InnoDB;
--source include/update_use_source.inc
--echo Test with an index on updated columns
create index t1_c2 on t1 (c2,c1);
--source include/update_use_source_ext.inc
--echo #######################################
--echo # #
--echo # Engine Aria #
--echo # #
--echo #######################################
set default_storage_engine=Aria;
--source include/update_use_source.inc
--echo Test with an index on updated columns
create index t1_c3 on t1 (c3);
--source include/update_use_source_ext.inc
--echo #######################################
--echo # #
--echo # Engine MyISAM #
--echo # #
--echo #######################################
set default_storage_engine=MyISAM;
--source include/update_use_source.inc
--echo Test with a primary key on updated columns
drop index t1_c3 on t1;
alter table t1 add primary key (c3);
--source include/update_use_source_ext.inc
--echo #######################################
--echo # #
--echo # Engine MEMORY #
--echo # #
--echo #######################################
set default_storage_engine=MEMORY;
--source include/update_use_source.inc
--echo # Update with error "Subquery returns more than 1 row"
--error ER_SUBQUERY_NO_1_ROW
update t1 set c2=(select c2 from t1);
--echo # Update with error "Subquery returns more than 1 row" and order by
--error ER_SUBQUERY_NO_1_ROW
update t1 set c2=(select c2 from t1) order by c3;
-- echo Duplicate value on update a primary key
start transaction;
--error ER_DUP_ENTRY
update t1 set c3=0 where exists (select 'X' from t1 a where a.c2 = t1.c2) and c2 >= 3;
rollback;
-- echo Duplicate value on update a primary key with ignore
start transaction;
--enable_info ONCE
update ignore t1 set c3=0 where exists (select 'X' from t1 a where a.c2 = t1.c2) and c2 >= 3;
rollback;
-- echo Duplicate value on update a primary key and limit
start transaction;
--error ER_DUP_ENTRY
update t1 set c3=0 where exists (select 'X' from t1 a where a.c2 = t1.c2) and c2 >= 3 limit 2;
rollback;
-- echo Duplicate value on update a primary key with ignore and limit
start transaction;
--enable_info ONCE
update ignore t1 set c3=0 where exists (select 'X' from t1 a where a.c2 = t1.c2) and c2 >= 3 limit 2;
rollback;
--echo # Update no rows found
--enable_info ONCE
update t1
set c1=10
where c1 <2
and exists (select 'X'
from t1 a
where a.c1 = t1.c1 + 10);
--echo # Update no rows changed
drop trigger trg_t1;
start transaction;
--enable_info ONCE
update t1
set c1=c1
where c1 <2
and exists (select 'X'
from t1 a
where a.c1 = t1.c1);
rollback;
--echo #
--echo # Check call of after trigger
--echo #
delimiter /;
create or replace trigger trg_t2 after update on t1 for each row
begin
declare msg varchar(100);
if (new.c3 = 5) then
set msg=concat('in after update trigger on ',new.c3);
SIGNAL SQLSTATE '45000' SET MESSAGE_TEXT = msg;
end if;
end;
/
delimiter ;/
--error 1644
update t1 set c1=2 where c3 in (select distinct a.c3 from t1 a where a.c1=t1.c1);
--echo #
--echo # Check update with order by and after trigger
--echo #
--error 1644
update t1 set c1=2 where c3 in (select distinct a.c3 from t1 a where a.c1=t1.c1) order by t1.c2;
drop view v1;
--echo #
--echo # Check update on view with check option
--echo #
create view v1 as select * from t1 where c2=2 with check option;
start transaction;
-- error 1369
update v1 set c2=3 where c1=1;
rollback;
start transaction;
-- error 1369
update v1 set c2=(select max(c3) from v1) where c1=1;
rollback;
start transaction;
update v1 set c2=(select min(va.c3) from v1 va), c1=0 where c1=1;
rollback;
drop view v1;
drop table t1;
--echo #
--echo # Test with a temporary table
--echo #
create temporary table t1 (c1 integer, c2 integer, c3 integer) engine=InnoDb;
insert into t1(c1,c2,c3) values (1,1,1);
insert into t1(c1,c2,c3) values (1,2,2);
insert into t1(c1,c2,c3) values (1,3,3);
insert into t1(c1,c2,c3) values (2,1,4);
insert into t1(c1,c2,c3) values (2,2,5);
insert into t1(c1,c2,c3) values (2,3,6);
insert into t1(c1,c2,c3) values (2,4,7);
insert into t1(c1,c2,c3) values (2,5,8);
start transaction;
--enable_info ONCE
update t1
set c1=(select a.c2
from t1 a
where a.c3 = t1.c3) limit 3;
select * from t1 ;
rollback;
drop table t1;
--echo #
--echo # Test on dynamic columns (blob)
--echo #
create table assets (
item_name varchar(32) primary key, -- A common attribute for all items
dynamic_cols blob -- Dynamic columns will be stored here
);
INSERT INTO assets VALUES ('MariaDB T-shirt', COLUMN_CREATE('color', 'blue', 'size', 'XL'));
INSERT INTO assets VALUES ('Thinkpad Laptop', COLUMN_CREATE('color', 'black', 'price', 500));
SELECT item_name, COLUMN_GET(dynamic_cols, 'color' as char) AS color FROM assets;
UPDATE assets SET dynamic_cols=COLUMN_ADD(dynamic_cols, 'warranty', '3 years') WHERE item_name='Thinkpad Laptop';
SELECT item_name, COLUMN_GET(dynamic_cols, 'warranty' as char) AS color FROM assets;
UPDATE assets SET dynamic_cols=COLUMN_ADD(dynamic_cols, 'warranty', '4 years')
WHERE item_name in (select b.item_name
from assets b
where COLUMN_GET(b.dynamic_cols, 'color' as char) ='black');
SELECT item_name, COLUMN_GET(dynamic_cols, 'warranty' as char) AS color FROM assets;
UPDATE assets SET dynamic_cols=COLUMN_ADD(dynamic_cols, 'warranty', (select COLUMN_GET(b.dynamic_cols, 'color' as char)
from assets b
where assets.item_name = item_name));
SELECT item_name, COLUMN_GET(dynamic_cols, 'warranty' as char) AS color FROM assets;
drop table assets ;
--echo #
--echo # Test on fulltext columns
--echo #
CREATE TABLE ft2(copy TEXT,FULLTEXT(copy)) ENGINE=MyISAM;
INSERT INTO ft2(copy) VALUES
('MySQL vs MariaDB database'),
('Oracle vs MariaDB database'),
('PostgreSQL vs MariaDB database'),
('MariaDB overview'),
('Foreign keys'),
('Primary keys'),
('Indexes'),
('Transactions'),
('Triggers');
SELECT * FROM ft2 WHERE MATCH(copy) AGAINST('database');
update ft2 set copy = (select max(concat('mykeyword ',substr(b.copy,1,5))) from ft2 b WHERE MATCH(b.copy) AGAINST('database'))
where MATCH(copy) AGAINST('keys');
SELECT * FROM ft2 WHERE MATCH(copy) AGAINST('mykeyword');
drop table ft2;
set @@default_storage_engine=@save_default_engine;
--echo #
--echo # Test with MyISAM
--echo #
create table t1 (old_c1 integer, old_c2 integer,c1 integer, c2 integer, c3 integer) engine=MyISAM;
create table t1 (old_c1 integer,
old_c2 integer,
c1 integer,
c2 integer,
c3 integer) engine=MyISAM;
insert t1 (c1,c2,c3) select 0,seq,seq%10 from seq_1_to_500;
insert t1 (c1,c2,c3) select 1,seq,seq%10 from seq_1_to_400;
insert t1 (c1,c2,c3) select 2,seq,seq%10 from seq_1_to_300;
......@@ -232,12 +66,14 @@ drop table t1;
--echo #
--echo # Test error on multi_update conversion on view with order by or limit
--echo # Test error on multi_update conversion on view
--echo # with order by or limit
--echo #
create table t1 (c1 integer) engine=InnoDb;
create table t2 (c1 integer) engine=InnoDb;
create view v1 as select t1.c1 as "t1c1" ,t2.c1 as "t2c1" from t1,t2 where t1.c1=t2.c1;
create view v1 as select t1.c1 as "t1c1" ,t2.c1 as "t2c1"
from t1,t2 where t1.c1=t2.c1;
# 'order by 1' should be considered as in 'select * from v1 order 1'
update v1 set t1c1=2 order by 1;
update v1 set t1c1=2 limit 1;
......
......@@ -1146,3 +1146,104 @@ ERROR 42000: You have an error in your SQL syntax; check the manual that corresp
#
# End of 10.9 tests
#
#
# MDEV-29390: Improve coverage for UPDATE and DELETE statements in MTR test suites
#
# Multi-update with JSON_TABLE
create table t1 ( name varchar(10),
color varchar(10),
price decimal(8,2),
instock BOOLEAN);
insert into t1 values ("Laptop", "black", 20000, 1);
insert into t1 values ("Jacket", "brown", 5000, 1);
insert into t1 values ("Jeans", "blue", 5000, 1);
select * from t1;
name color price instock
Laptop black 20000.00 1
Jacket brown 5000.00 1
Jeans blue 5000.00 1
set @json='
[
{"name":"Laptop", "color":"black", "price":"1000", "ordered":"3"},
{"name":"Jeans", "color":"blue", "ordered":"0"},
{"name":"Phone", "color":"red", "ordered":"0"}
]';
select * from json_table(@json, '$[*]'
columns(
name varchar(10) path '$.name',
color varchar(10) path '$.color',
price decimal(8,2) path '$.price',
ordered boolean path '$.ordered' )
) as jt;
name color price ordered
Laptop black 1000.00 3
Jeans blue NULL 0
Phone red NULL 0
explain update t1, JSON_TABLE(@json,'$[*]'
COLUMNS (
name varchar(10) path '$.name',
color varchar(10) path '$.color',
price decimal(8,2) path '$.price',
ordered boolean path '$.ordered'
)) AS jt1
SET t1.instock=0 where t1.name=jt1.name and jt1.ordered=3;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 3
1 SIMPLE jt1 ALL NULL NULL NULL NULL 40 Table function: json_table; Using where
update t1, JSON_TABLE(@json,'$[*]'
COLUMNS (
name varchar(10) path '$.name',
color varchar(10) path '$.color',
price decimal(8,2) path '$.price',
ordered boolean path '$.ordered'
)) AS jt1
SET t1.instock=0 where t1.name=jt1.name and jt1.ordered=2;
select * from t1;
name color price instock
Laptop black 20000.00 1
Jacket brown 5000.00 1
Jeans blue 5000.00 1
explain update t1
SET t1.instock=2 where t1.name in (
select jt1.name from json_table(@json, '$[*]'
columns(
name varchar(10) path '$.name',
color varchar(10) path '$.color',
price decimal(8,2) path '$.price',
ordered boolean path '$.ordered' )
) as jt1);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 3
1 PRIMARY jt1 ALL NULL NULL NULL NULL 40 Table function: json_table; Using where; FirstMatch(t1)
update t1
SET t1.instock=2 where t1.name in (
select jt1.name from json_table(@json, '$[*]'
columns(
name varchar(10) path '$.name',
color varchar(10) path '$.color',
price decimal(8,2) path '$.price',
ordered boolean path '$.ordered' )
) as jt1);
select * from t1;
name color price instock
Laptop black 20000.00 2
Jacket brown 5000.00 1
Jeans blue 5000.00 2
update t1, JSON_TABLE(@json,'$[*]'
COLUMNS (
name varchar(10) path '$.name',
color varchar(10) path '$.color',
price decimal(8,2) path '$.price',
ordered boolean path '$.ordered'
)) AS jt1
SET t1.instock=0, jt1.ordered=1 where t1.name=jt1.name;
ERROR HY000: The target table jt1 of the UPDATE is not updatable
select * from t1;
name color price instock
Laptop black 20000.00 2
Jacket brown 5000.00 1
Jeans blue 5000.00 2
drop table t1;
#
# End of 11.0 tests
#
......@@ -997,3 +997,97 @@ COLUMNS
--echo #
--echo # End of 10.9 tests
--echo #
--echo #
--echo # MDEV-29390: Improve coverage for UPDATE and DELETE statements in MTR test suites
--echo #
--echo # Multi-update with JSON_TABLE
create table t1 ( name varchar(10),
color varchar(10),
price decimal(8,2),
instock BOOLEAN);
insert into t1 values ("Laptop", "black", 20000, 1);
insert into t1 values ("Jacket", "brown", 5000, 1);
insert into t1 values ("Jeans", "blue", 5000, 1);
select * from t1;
set @json='
[
{"name":"Laptop", "color":"black", "price":"1000", "ordered":"3"},
{"name":"Jeans", "color":"blue", "ordered":"0"},
{"name":"Phone", "color":"red", "ordered":"0"}
]';
select * from json_table(@json, '$[*]'
columns(
name varchar(10) path '$.name',
color varchar(10) path '$.color',
price decimal(8,2) path '$.price',
ordered boolean path '$.ordered' )
) as jt;
explain update t1, JSON_TABLE(@json,'$[*]'
COLUMNS (
name varchar(10) path '$.name',
color varchar(10) path '$.color',
price decimal(8,2) path '$.price',
ordered boolean path '$.ordered'
)) AS jt1
SET t1.instock=0 where t1.name=jt1.name and jt1.ordered=3;
update t1, JSON_TABLE(@json,'$[*]'
COLUMNS (
name varchar(10) path '$.name',
color varchar(10) path '$.color',
price decimal(8,2) path '$.price',
ordered boolean path '$.ordered'
)) AS jt1
SET t1.instock=0 where t1.name=jt1.name and jt1.ordered=2;
select * from t1;
explain update t1
SET t1.instock=2 where t1.name in (
select jt1.name from json_table(@json, '$[*]'
columns(
name varchar(10) path '$.name',
color varchar(10) path '$.color',
price decimal(8,2) path '$.price',
ordered boolean path '$.ordered' )
) as jt1);
update t1
SET t1.instock=2 where t1.name in (
select jt1.name from json_table(@json, '$[*]'
columns(
name varchar(10) path '$.name',
color varchar(10) path '$.color',
price decimal(8,2) path '$.price',
ordered boolean path '$.ordered' )
) as jt1);
select * from t1;
-- error ER_NON_UPDATABLE_TABLE
update t1, JSON_TABLE(@json,'$[*]'
COLUMNS (
name varchar(10) path '$.name',
color varchar(10) path '$.color',
price decimal(8,2) path '$.price',
ordered boolean path '$.ordered'
)) AS jt1
SET t1.instock=0, jt1.ordered=1 where t1.name=jt1.name;
select * from t1;
drop table t1;
--echo #
--echo # End of 11.0 tests
--echo #
......@@ -1627,3 +1627,159 @@ serialno name sex title manager department secretary salary
DROP PROCEDURE test.tst_up;
DROP TABLE employee;
SET sql_mode = DEFAULT;
#
# End of 10.10 tests
#
SET sql_mode = 'NO_ENGINE_SUBSTITUTION';
CREATE TABLE t1
(
name char(12) not null,
city char(11) not null,
birth date not null date_format='DD/MM/YYYY',
hired date not null date_format='DD/MM/YYYY' flag=36
) ENGINE=CONNECT TABLE_TYPE=FIX FILE_NAME='boys.txt' ENDING=1;
CREATE TABLE t2 (
_id INT(2) NOT NULL,
name_first CHAR(9) NOT NULL JPATH='$.name.first',
name_aka CHAR(4) DEFAULT NULL JPATH='$.name.aka',
name_last CHAR(10) NOT NULL JPATH='$.name.last',
title CHAR(12) DEFAULT NULL,
birth CHAR(20) DEFAULT NULL,
death CHAR(20) DEFAULT NULL,
contribs CHAR(50) NOT NULL JPATH='$.contribs',
awards_award CHAR(42) DEFAULT NULL JPATH='$.awards.award',
awards_year CHAR(4) DEFAULT NULL JPATH='$.awards.year',
awards_by CHAR(38) DEFAULT NULL JPATH='$.awards.by'
) ENGINE=CONNECT TABLE_TYPE=JSON FILE_NAME='bios.json';
# Multi-update
select t1.name, t1.city from t1;
name city
John Boston
Henry Boston
George San Jose
Sam Chicago
James Dallas
Bill Boston
select t2._id, t2.name_first, t2.name_aka, t2.name_last from t2;
_id name_first name_aka name_last
1 John NULL Backus
2 John NULL McCarthy
3 Grace NULL Hopper
4 Kristen NULL Nygaard
5 Ole-Johan NULL Dahl
6 Guido NULL van Rossum
7 Dennis NULL Ritchie
8 Yukihiro Matz Matsumoto
9 James NULL Gosling
10 Martin NULL Odersky
select t1.name, t2.name_last, t2.name_aka, t1.city from t1, t2 where t1.name=t2.name_first and t1.birth
BETWEEN '1992-01-01' and '1995-01-01';
name name_last name_aka city
James Gosling NULL Dallas
explain update t1, t2
set t1.city='Washington', t2.name_aka='von' where t1.name=t2.name_first and t1.birth
BETWEEN '1992-01-01' and '1995-01-01';
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 6 Using where
1 SIMPLE t2 ALL NULL NULL NULL NULL 10 Using where
update t1, t2
set t1.city='Washington', t2.name_aka='von' where t1.name=t2.name_first and t1.birth
BETWEEN '1992-01-01' and '1995-01-01';
select t1.name, t2.name_last, t2.name_aka, t1.city from t1, t2 where t1.name=t2.name_first and t1.birth
BETWEEN '1992-01-01' and '1995-01-01';
name name_last name_aka city
James Gosling von Washington
# Conversion to multi-update
select t1.name, t1.city from t1;
name city
John Boston
Henry Boston
George San Jose
Sam Chicago
James Washington
Bill Boston
explain update t1
set t1.city='New York' where t1.name in (select t2.name_first from t2);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 6
1 PRIMARY t2 ALL NULL NULL NULL NULL 10 Using where; FirstMatch(t1)
update t1
set t1.city='New York' where t1.name in (select t2.name_first from t2);
select t1.name, t1.city from t1;
name city
John New York
Henry Boston
George San Jose
Sam Chicago
James New York
Bill Boston
select t1.name, t1.city from t1 where t1.name in (select a.name from t1 as a where a.birth
BETWEEN '1981-01-01' and '1982-01-01');
name city
George San Jose
explain update t1 set t1.city='Los Angeles' where t1.name in (select a.name from t1 as a where a.birth
BETWEEN '1981-01-01' and '1982-01-01');
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 6
1 PRIMARY a ALL NULL NULL NULL NULL 6 Using where; FirstMatch(t1)
update t1 set t1.city='Los Angeles' where t1.name in (select a.name from t1 as a where a.birth
BETWEEN '1981-01-01' and '1982-01-01');
select t1.name, t1.city from t1 where t1.name in (select a.name from t1 as a where a.birth
BETWEEN '1981-01-01' and '1982-01-01');
name city
George Los Angeles
# Multi-delete
explain delete t1.*, t2.* from t1, t2 where t1.name=t2.name_first and t1.birth
BETWEEN '1992-01-01' and '1995-01-01';
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL NULL NULL NULL NULL 6 Using where
1 SIMPLE t2 ALL NULL NULL NULL NULL 10 Using where
delete t1.*, t2.* from t1, t2 where t1.name=t2.name_first and t1.birth
BETWEEN '1992-01-01' and '1995-01-01';
select t1.name, t1.city from t1;
name city
John New York
Henry Boston
George Los Angeles
Sam Chicago
Bill Boston
select t2._id, t2.name_first, t2.name_aka, t2.name_last from t2;
_id name_first name_aka name_last
1 John NULL Backus
2 John NULL McCarthy
3 Grace NULL Hopper
4 Kristen NULL Nygaard
5 Ole-Johan NULL Dahl
6 Guido NULL van Rossum
7 Dennis NULL Ritchie
8 Yukihiro Matz Matsumoto
10 Martin NULL Odersky
# Conversion to multi-delete
explain delete from t1 where t1.name in (select t2.name_first from t2);
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 5
1 PRIMARY t2 ALL NULL NULL NULL NULL 9 Using where; FirstMatch(t1)
delete from t1 where t1.name in (select t2.name_first from t2);
select t1.name, t1.city from t1;
name city
Henry Boston
George Los Angeles
Sam Chicago
Bill Boston
explain delete from t1 where t1.name in (select a.name from t1 as a where a.birth
BETWEEN '1981-01-01' and '1982-01-01');
id select_type table type possible_keys key key_len ref rows Extra
1 PRIMARY t1 ALL NULL NULL NULL NULL 4
1 PRIMARY a ALL NULL NULL NULL NULL 4 Using where; FirstMatch(t1)
delete from t1 where t1.name in (select a.name from t1 as a where a.birth
BETWEEN '1981-01-01' and '1982-01-01');
select t1.name, t1.city from t1;
name city
Henry Boston
Sam Chicago
Bill Boston
drop tables t1, t2;
SET sql_mode = DEFAULT;
#
# End of 11.0 tests
#
......@@ -155,3 +155,99 @@ DROP TABLE employee;
SET sql_mode = DEFAULT;
--remove_file $MYSQLD_DATADIR/test/employee.dat
--echo #
--echo # End of 10.10 tests
--echo #
--copy_file $MTR_SUITE_DIR/std_data/boys.txt $MYSQLD_DATADIR/test/boys.txt
--copy_file $MTR_SUITE_DIR/std_data/bios.json $MYSQLD_DATADIR/test/bios.json
SET sql_mode = 'NO_ENGINE_SUBSTITUTION';
CREATE TABLE t1
(
name char(12) not null,
city char(11) not null,
birth date not null date_format='DD/MM/YYYY',
hired date not null date_format='DD/MM/YYYY' flag=36
) ENGINE=CONNECT TABLE_TYPE=FIX FILE_NAME='boys.txt' ENDING=1;
CREATE TABLE t2 (
_id INT(2) NOT NULL,
name_first CHAR(9) NOT NULL JPATH='$.name.first',
name_aka CHAR(4) DEFAULT NULL JPATH='$.name.aka',
name_last CHAR(10) NOT NULL JPATH='$.name.last',
title CHAR(12) DEFAULT NULL,
birth CHAR(20) DEFAULT NULL,
death CHAR(20) DEFAULT NULL,
contribs CHAR(50) NOT NULL JPATH='$.contribs',
awards_award CHAR(42) DEFAULT NULL JPATH='$.awards.award',
awards_year CHAR(4) DEFAULT NULL JPATH='$.awards.year',
awards_by CHAR(38) DEFAULT NULL JPATH='$.awards.by'
) ENGINE=CONNECT TABLE_TYPE=JSON FILE_NAME='bios.json';
--echo # Multi-update
select t1.name, t1.city from t1;
select t2._id, t2.name_first, t2.name_aka, t2.name_last from t2;
let $c1 = where t1.name=t2.name_first and t1.birth
BETWEEN '1992-01-01' and '1995-01-01';
eval select t1.name, t2.name_last, t2.name_aka, t1.city from t1, t2 $c1;
eval explain update t1, t2
set t1.city='Washington', t2.name_aka='von' $c1;
eval update t1, t2
set t1.city='Washington', t2.name_aka='von' $c1;
eval select t1.name, t2.name_last, t2.name_aka, t1.city from t1, t2 $c1;
--echo # Conversion to multi-update
let $c2 = where t1.name in (select t2.name_first from t2);
select t1.name, t1.city from t1;
eval explain update t1
set t1.city='New York' $c2;
eval update t1
set t1.city='New York' $c2;
select t1.name, t1.city from t1;
let $c3 = where t1.name in (select a.name from t1 as a where a.birth
BETWEEN '1981-01-01' and '1982-01-01');
eval select t1.name, t1.city from t1 $c3;
eval explain update t1 set t1.city='Los Angeles' $c3;
eval update t1 set t1.city='Los Angeles' $c3;
eval select t1.name, t1.city from t1 $c3;
--echo # Multi-delete
eval explain delete t1.*, t2.* from t1, t2 $c1;
eval delete t1.*, t2.* from t1, t2 $c1;
select t1.name, t1.city from t1;
select t2._id, t2.name_first, t2.name_aka, t2.name_last from t2;
--echo # Conversion to multi-delete
eval explain delete from t1 $c2;
eval delete from t1 $c2;
select t1.name, t1.city from t1;
eval explain delete from t1 $c3;
eval delete from t1 $c3;
select t1.name, t1.city from t1;
drop tables t1, t2;
SET sql_mode = DEFAULT;
--remove_file $MYSQLD_DATADIR/test/boys.txt
--remove_file $MYSQLD_DATADIR/test/bios.json
--echo #
--echo # End of 11.0 tests
--echo #
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment