Skip to content

Commit

Permalink
feat(core): support select ... where like null stoneatom#669
Browse files Browse the repository at this point in the history
[summary]
1. This pr is ported from 5.7, related issue stoneatom#763
2. As where like null is supported, the sql 'select * from tlike where val like NULL;'
   executed crashed in debug mode alse be resolved in mtr issue410.test.
3. open mtr test: issue410.test
  • Loading branch information
hustjieke committed Dec 5, 2022
1 parent f734834 commit 916a418
Show file tree
Hide file tree
Showing 5 changed files with 236 additions and 4 deletions.
2 changes: 0 additions & 2 deletions mysql-test/suite/tianmu/r/issue410.result
Original file line number Diff line number Diff line change
Expand Up @@ -3,6 +3,4 @@ create table tlike (val varchar(255)) ENGINE=TIANMU;
insert into tlike values ('abcde');
select * from tlike where val like NULL;
val
Warnings:
Note 1105 Query syntax not implemented in TIANMU, executed by MySQL engine.
drop table tlike;
160 changes: 160 additions & 0 deletions mysql-test/suite/tianmu/r/issue763.result
Original file line number Diff line number Diff line change
@@ -0,0 +1,160 @@
#
# SELECT ... FROM tablename WHERE col LIKE NULL
#
DROP DATABASE IF EXISTS test_like_null;
CREATE DATABASE test_like_null;
USE test_like_null;
create table tlike1 (id int, val varchar(255));
INSERT INTO tlike1 VALUES(1,'a'), (1,'b'), (1,'c'), (2,'dd'), (3,'eee'), (4, NULL), (5, NULL);
SELECT * FROM tlike1;
id val
1 a
1 b
1 c
2 dd
3 eee
4 NULL
5 NULL
SELECT * FROM tlike1 WHERE val is NULL;
id val
4 NULL
5 NULL
SELECT * FROM tlike1 WHERE val LIKE NULL;
id val
SELECT COUNT(*) FROM tlike1 WHERE val LIKE NULL;
COUNT(*)
0
SELECT id, val FROM tlike1 WHERE id=1 and val LIKE NULL;
id val
SELECT id, val FROM tlike1 WHERE id=1 or val LIKE NULL;
id val
1 a
1 b
1 c
SELECT id, val FROM tlike1 WHERE id in (4, 5) and val LIKE NULL;
id val
SELECT id, val FROM tlike1 WHERE id in (4, 5) or val LIKE NULL;
id val
4 NULL
5 NULL
create table tlike2 (id int, val varchar(255));
INSERT INTO tlike2 VALUES(1,'a'), (1,'b'), (1,'c'), (2,'dd'), (3,'eee'), (4, ""), (5, NULL);
SELECT * FROM tlike2;
id val
1 a
1 b
1 c
2 dd
3 eee
4
5 NULL
SELECT * FROM tlike2 WHERE val is NULL;
id val
5 NULL
SELECT * FROM tlike2 WHERE val LIKE NULL;
id val
SELECT * FROM tlike2 WHERE val LIKE "";
id val
4
SELECT COUNT(*) FROM tlike2 WHERE val LIKE NULL;
COUNT(*)
0
SELECT id, val FROM tlike2 WHERE id=1 and val LIKE NULL;
id val
SELECT id, val FROM tlike2 WHERE id=1 or val LIKE NULL;
id val
1 a
1 b
1 c
SELECT id, val FROM tlike2 WHERE id in (4, 5) and val LIKE NULL;
id val
SELECT id, val FROM tlike2 WHERE id in (4, 5) or val LIKE NULL;
id val
4
5 NULL
create table tlike3 (id int, val varchar(255));
INSERT INTO tlike3 VALUES(1,'a'), (1,'b'), (1,'c'), (2,'dd'), (3,'eee'), (4, ""), (5, "ggggg");
SELECT * FROM tlike3;
id val
1 a
1 b
1 c
2 dd
3 eee
4
5 ggggg
SELECT * FROM tlike3 WHERE val is NULL;
id val
SELECT * FROM tlike3 WHERE val LIKE NULL;
id val
SELECT COUNT(*) FROM tlike3 WHERE val LIKE NULL;
COUNT(*)
0
SELECT id, val FROM tlike3 WHERE id=1 and val LIKE NULL;
id val
SELECT id, val FROM tlike3 WHERE id=1 or val LIKE NULL;
id val
1 a
1 b
1 c
SELECT id, val FROM tlike3 WHERE id in (4, 5) and val LIKE NULL;
id val
SELECT id, val FROM tlike3 WHERE id in (4, 5) or val LIKE NULL;
id val
4
5 ggggg
create table tlike4 (id int, val varchar(255));
INSERT INTO tlike4 VALUES(1,'a'), (1,'b'), (1,'c'), (2,'dd'), (3,'eee'), (4, "ffff"), (5, "ggggg");
SELECT * FROM tlike4;
id val
1 a
1 b
1 c
2 dd
3 eee
4 ffff
5 ggggg
SELECT * FROM tlike4 WHERE val is NULL;
id val
SELECT * FROM tlike4 WHERE val LIKE NULL;
id val
SELECT COUNT(*) FROM tlike4 WHERE val LIKE NULL;
COUNT(*)
0
SELECT id, val FROM tlike4 WHERE id=1 and val LIKE NULL;
id val
SELECT id, val FROM tlike4 WHERE id=1 or val LIKE NULL;
id val
1 a
1 b
1 c
SELECT id, val FROM tlike4 WHERE id in (4, 5) and val LIKE NULL;
id val
SELECT id, val FROM tlike4 WHERE id in (4, 5) or val LIKE NULL;
id val
4 ffff
5 ggggg
SELECT t1.id, t1.val FROM tlike1 t1, tlike2 t2 where t1.id=t2.id and t1.val like NULL;
id val
SELECT t1.id, t1.val FROM tlike1 t1, tlike2 t2 where t1.id=t2.id and t2.val like NULL;
id val
SELECT t1.id, t1.val FROM tlike1 t1, tlike2 t2 where t1.id=t2.id and t1.val like NULL and t2.val like NULL;
id val
SELECT t1.id, t1.val FROM tlike1 t1, tlike2 t2 where t1.id=t2.id and t1.val is NULL;
id val
4 NULL
5 NULL
SELECT t1.id, t1.val FROM tlike1 t1, tlike2 t2 where t1.id=t2.id and t2.val is NULL;
id val
5 NULL
SELECT t1.id, t1.val FROM tlike1 t1, tlike2 t2 where t1.id=t2.id and t1.val is NULL and t2.val is NULL;
id val
5 NULL
SELECT id, val FROM tlike1 WHERE val LIKE NULL union all SELECT id, val FROM tlike2 WHERE id in (4,5) and val LIKE NULL;
id val
SELECT id, val FROM tlike1 WHERE val is NULL union all SELECT id, val FROM tlike2 WHERE id in (4,5) and val is NULL;
id val
4 NULL
5 NULL
5 NULL
DROP DATABASE test_like_null;
File renamed without changes.
73 changes: 73 additions & 0 deletions mysql-test/suite/tianmu/t/issue763.test
Original file line number Diff line number Diff line change
@@ -0,0 +1,73 @@
--source include/have_tianmu.inc

--echo #
--echo # SELECT ... FROM tablename WHERE col LIKE NULL
--echo #

--disable_warnings
DROP DATABASE IF EXISTS test_like_null;
--enable_warnings

CREATE DATABASE test_like_null;
USE test_like_null;

create table tlike1 (id int, val varchar(255));
INSERT INTO tlike1 VALUES(1,'a'), (1,'b'), (1,'c'), (2,'dd'), (3,'eee'), (4, NULL), (5, NULL);
SELECT * FROM tlike1;
SELECT * FROM tlike1 WHERE val is NULL;
SELECT * FROM tlike1 WHERE val LIKE NULL;
SELECT COUNT(*) FROM tlike1 WHERE val LIKE NULL;
SELECT id, val FROM tlike1 WHERE id=1 and val LIKE NULL;
SELECT id, val FROM tlike1 WHERE id=1 or val LIKE NULL;
SELECT id, val FROM tlike1 WHERE id in (4, 5) and val LIKE NULL;
SELECT id, val FROM tlike1 WHERE id in (4, 5) or val LIKE NULL;

create table tlike2 (id int, val varchar(255));
INSERT INTO tlike2 VALUES(1,'a'), (1,'b'), (1,'c'), (2,'dd'), (3,'eee'), (4, ""), (5, NULL);
SELECT * FROM tlike2;
SELECT * FROM tlike2 WHERE val is NULL;
SELECT * FROM tlike2 WHERE val LIKE NULL;
SELECT * FROM tlike2 WHERE val LIKE "";
SELECT COUNT(*) FROM tlike2 WHERE val LIKE NULL;
SELECT id, val FROM tlike2 WHERE id=1 and val LIKE NULL;
SELECT id, val FROM tlike2 WHERE id=1 or val LIKE NULL;
SELECT id, val FROM tlike2 WHERE id in (4, 5) and val LIKE NULL;
SELECT id, val FROM tlike2 WHERE id in (4, 5) or val LIKE NULL;

create table tlike3 (id int, val varchar(255));
INSERT INTO tlike3 VALUES(1,'a'), (1,'b'), (1,'c'), (2,'dd'), (3,'eee'), (4, ""), (5, "ggggg");
SELECT * FROM tlike3;
SELECT * FROM tlike3 WHERE val is NULL;
SELECT * FROM tlike3 WHERE val LIKE NULL;
SELECT COUNT(*) FROM tlike3 WHERE val LIKE NULL;
SELECT id, val FROM tlike3 WHERE id=1 and val LIKE NULL;
SELECT id, val FROM tlike3 WHERE id=1 or val LIKE NULL;
SELECT id, val FROM tlike3 WHERE id in (4, 5) and val LIKE NULL;
SELECT id, val FROM tlike3 WHERE id in (4, 5) or val LIKE NULL;

create table tlike4 (id int, val varchar(255));
INSERT INTO tlike4 VALUES(1,'a'), (1,'b'), (1,'c'), (2,'dd'), (3,'eee'), (4, "ffff"), (5, "ggggg");
SELECT * FROM tlike4;
SELECT * FROM tlike4 WHERE val is NULL;
SELECT * FROM tlike4 WHERE val LIKE NULL;
SELECT COUNT(*) FROM tlike4 WHERE val LIKE NULL;
SELECT id, val FROM tlike4 WHERE id=1 and val LIKE NULL;
SELECT id, val FROM tlike4 WHERE id=1 or val LIKE NULL;
SELECT id, val FROM tlike4 WHERE id in (4, 5) and val LIKE NULL;
SELECT id, val FROM tlike4 WHERE id in (4, 5) or val LIKE NULL;

# test multi table
SELECT t1.id, t1.val FROM tlike1 t1, tlike2 t2 where t1.id=t2.id and t1.val like NULL;
SELECT t1.id, t1.val FROM tlike1 t1, tlike2 t2 where t1.id=t2.id and t2.val like NULL;
SELECT t1.id, t1.val FROM tlike1 t1, tlike2 t2 where t1.id=t2.id and t1.val like NULL and t2.val like NULL;

SELECT t1.id, t1.val FROM tlike1 t1, tlike2 t2 where t1.id=t2.id and t1.val is NULL;
SELECT t1.id, t1.val FROM tlike1 t1, tlike2 t2 where t1.id=t2.id and t2.val is NULL;
SELECT t1.id, t1.val FROM tlike1 t1, tlike2 t2 where t1.id=t2.id and t1.val is NULL and t2.val is NULL;

# test union all
SELECT id, val FROM tlike1 WHERE val LIKE NULL union all SELECT id, val FROM tlike2 WHERE id in (4,5) and val LIKE NULL;
SELECT id, val FROM tlike1 WHERE val is NULL union all SELECT id, val FROM tlike2 WHERE id in (4,5) and val is NULL;

# Clean UP
DROP DATABASE test_like_null;
5 changes: 3 additions & 2 deletions storage/tianmu/core/query.cpp
Original file line number Diff line number Diff line change
Expand Up @@ -1343,8 +1343,9 @@ CondID Query::ConditionNumberFromComparison(Item *conds, const TableID &tmp_tabl
return CondID(-1);
if ((op == common::Operator::O_LIKE || op == common::Operator::O_NOT_LIKE) &&
!(an_arg->data_type() == MYSQL_TYPE_VARCHAR || an_arg->data_type() == MYSQL_TYPE_STRING ||
an_arg->data_type() == MYSQL_TYPE_VAR_STRING || an_arg->data_type() == MYSQL_TYPE_BLOB)) {
return CondID(-1); // Argument of LIKE is not a string, return to MySQL.
an_arg->data_type() == MYSQL_TYPE_VAR_STRING || an_arg->data_type() == MYSQL_TYPE_BLOB ||
an_arg->data_type() == MYSQL_TYPE_NULL)) { // issue: #763, Argument of LIKE is NULL
return CondID(-1); // Argument of LIKE is not a string or null, return to MySQL.
}
}
}
Expand Down

0 comments on commit 916a418

Please sign in to comment.