diff --git a/mysql-test/r/derived.result b/mysql-test/r/derived.result index be743be386bb180659180815075fe9fc6ea8835d..7e5c519e10801a2ba693be0ae51ce7ff642cf22e 100644 --- a/mysql-test/r/derived.result +++ b/mysql-test/r/derived.result @@ -320,3 +320,9 @@ id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY <derived2> system NULL NULL NULL NULL 1 2 DERIVED t2 range PRIMARY PRIMARY 4 NULL 2 Using where; Using index drop table t2; +CREATE TABLE `t1` ( `itemid` int(11) NOT NULL default '0', `grpid` varchar(15) NOT NULL default '', `vendor` int(11) NOT NULL default '0', `date_` date NOT NULL default '0000-00-00', `price` decimal(12,2) NOT NULL default '0.00', PRIMARY KEY (`itemid`,`grpid`,`vendor`,`date_`), KEY `itemid` (`itemid`,`vendor`), KEY `itemid_2` (`itemid`,`date_`)); +insert into t1 values (128, 'rozn', 2, now(), 10),(128, 'rozn', 1, now(), 10); +SELECT MIN(price) min, MAX(price) max, AVG(price) avg FROM (SELECT SUBSTRING( MAX(concat(date_,";",price)), 12) price FROM t1 WHERE itemid=128 AND grpid='rozn' GROUP BY itemid, grpid, vendor) lastprices; +min max avg +10.00 10.00 10 +DROP TABLE t1; diff --git a/mysql-test/r/subselect.result b/mysql-test/r/subselect.result index d4cc9c3192ac7a42127c28f61693f87621047cf2..1bfd74f01edf94e79bdf4167958a2d9066dd4c96 100644 --- a/mysql-test/r/subselect.result +++ b/mysql-test/r/subselect.result @@ -1160,9 +1160,9 @@ SELECT 0 IN (SELECT 1 FROM t1 a); EXPLAIN EXTENDED SELECT 0 IN (SELECT 1 FROM t1 a); id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used -2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE Warnings: -Note 1003 select high_priority <in_optimizer>(0,<exists>(select 1 AS `Not_used` from test.t1 a where isnull(1) having <is_not_null_test>(1) limit 1)) AS `0 IN (SELECT 1 FROM t1 a)` +Note 1003 select high_priority <in_optimizer>(0,<exists>(select 1 AS `Not_used` from test.t1 a limit 1)) AS `0 IN (SELECT 1 FROM t1 a)` INSERT INTO t1 (pseudo) VALUES ('test1'); SELECT 0 IN (SELECT 1 FROM t1 a); 0 IN (SELECT 1 FROM t1 a) @@ -1170,9 +1170,9 @@ SELECT 0 IN (SELECT 1 FROM t1 a); EXPLAIN EXTENDED SELECT 0 IN (SELECT 1 FROM t1 a); id select_type table type possible_keys key key_len ref rows Extra 1 PRIMARY NULL NULL NULL NULL NULL NULL NULL No tables used -2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE noticed after reading const tables +2 DEPENDENT SUBQUERY NULL NULL NULL NULL NULL NULL NULL Impossible WHERE Warnings: -Note 1003 select high_priority <in_optimizer>(0,<exists>(select 1 AS `Not_used` from test.t1 a where isnull(1) having <is_not_null_test>(1) limit 1)) AS `0 IN (SELECT 1 FROM t1 a)` +Note 1003 select high_priority <in_optimizer>(0,<exists>(select 1 AS `Not_used` from test.t1 a limit 1)) AS `0 IN (SELECT 1 FROM t1 a)` drop table t1; CREATE TABLE `t1` ( `i` int(11) NOT NULL default '0', @@ -1629,7 +1629,63 @@ insert into t1 values ('aaa'), ('bbb'),('eee'),('mmm'),('ppp'); select count(*) from t1 as w1 where w1.val in (select w2.val from t1 as w2 where w2.val like 'm%') and w1.val in (select w3.val from t1 as w3 where w3.val like 'e%'); count(*) 0 -drop table if exists t1; +drop table t1; +create table t1 (id int not null, text varchar(20) not null default '', primary key (id)); +insert into t1 (id, text) values (1, 'text1'), (2, 'text2'), (3, 'text3'), (4, 'text4'), (5, 'text5'), (6, 'text6'), (7, 'text7'), (8, 'text8'), (9, 'text9'), (10, 'text10'), (11, 'text11'), (12, 'text12'); +select * from t1 where id not in (select id from t1 where id < 8); +id text +8 text8 +9 text9 +10 text10 +11 text11 +12 text12 +select * from t1 as tt where not exists (select id from t1 where id < 8 and (id = tt.id or id is null) having id is not null); +id text +8 text8 +9 text9 +10 text10 +11 text11 +12 text12 +explain extended select * from t1 where id not in (select id from t1 where id < 8); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY t1 ALL NULL NULL NULL NULL 12 Using where +2 DEPENDENT SUBQUERY t1 unique_subquery PRIMARY PRIMARY 4 func 1 Using index; Using where +Warnings: +Note 1003 select high_priority test.t1.id AS `id`,test.t1.text AS `text` from test.t1 where not(<in_optimizer>(test.t1.id,<exists>(<primary_index_lookup>(<cache>(test.t1.id) in t1 on PRIMARY where (test.t1.id < 8))))) +explain extended select * from t1 as tt where not exists (select id from t1 where id < 8 and (id = tt.id or id is null) having id is not null); +id select_type table type possible_keys key key_len ref rows Extra +1 PRIMARY tt ALL NULL NULL NULL NULL 12 Using where +2 DEPENDENT SUBQUERY t1 eq_ref PRIMARY PRIMARY 4 test.tt.id 7 Using where; Using index +Warnings: +Note 1276 Field or reference 'tt.id' of SELECT #2 was resolved in SELECT #1 +Note 1003 select high_priority test.tt.id AS `id`,test.tt.text AS `text` from test.t1 tt where not(exists(select test.t1.id AS `id` from test.t1 where ((test.t1.id < 8) and ((test.t1.id = test.tt.id) or isnull(test.t1.id))) having (test.t1.id is not null) limit 1)) +insert into t1 (id, text) values (1000, 'text1000'), (1001, 'text1001'); +create table t2 (id int not null, text varchar(20) not null default '', primary key (id)); +insert into t2 (id, text) values (1, 'text1'), (2, 'text2'), (3, 'text3'), (4, 'text4'), (5, 'text5'), (6, 'text6'), (7, 'text7'), (8, 'text8'), (9, 'text9'), (10, 'text10'), (11, 'text1'), (12, 'text2'), (13, 'text3'), (14, 'text4'), (15, 'text5'), (16, 'text6'), (17, 'text7'), (18, 'text8'), (19, 'text9'), (20, 'text10'),(21, 'text1'), (22, 'text2'), (23, 'text3'), (24, 'text4'), (25, 'text5'), (26, 'text6'), (27, 'text7'), (28, 'text8'), (29, 'text9'), (30, 'text10'), (31, 'text1'), (32, 'text2'), (33, 'text3'), (34, 'text4'), (35, 'text5'), (36, 'text6'), (37, 'text7'), (38, 'text8'), (39, 'text9'), (40, 'text10'), (41, 'text1'), (42, 'text2'), (43, 'text3'), (44, 'text4'), (45, 'text5'), (46, 'text6'), (47, 'text7'), (48, 'text8'), (49, 'text9'), (50, 'text10'); +select * from t1 a left join t2 b on (a.id=b.id or b.id is null) join t1 c on (if(isnull(b.id), 1000, b.id)=c.id); +id text id text id text +1 text1 1 text1 1 text1 +2 text2 2 text2 2 text2 +3 text3 3 text3 3 text3 +4 text4 4 text4 4 text4 +5 text5 5 text5 5 text5 +6 text6 6 text6 6 text6 +7 text7 7 text7 7 text7 +8 text8 8 text8 8 text8 +9 text9 9 text9 9 text9 +10 text10 10 text10 10 text10 +11 text11 11 text1 11 text11 +12 text12 12 text2 12 text12 +1000 text1000 NULL NULL 1000 text1000 +1001 text1001 NULL NULL 1000 text1000 +explain extended select * from t1 a left join t2 b on (a.id=b.id or b.id is null) join t1 c on (if(isnull(b.id), 1000, b.id)=c.id); +id select_type table type possible_keys key key_len ref rows Extra +1 SIMPLE a ALL NULL NULL NULL NULL 14 +1 SIMPLE b eq_ref PRIMARY PRIMARY 4 test.a.id 2 +1 SIMPLE c eq_ref PRIMARY PRIMARY 4 func 1 Using where +Warnings: +Note 1003 select high_priority test.a.id AS `id`,test.a.text AS `text`,test.b.id AS `id`,test.b.text AS `text`,test.c.id AS `id`,test.c.text AS `text` from test.t1 a left join test.t2 b on(((test.a.id = test.b.id) or isnull(test.b.id))) join test.t1 c where (if(isnull(test.b.id),1000,test.b.id) = test.c.id) +drop table t1,t2; create table t1 (a int); insert into t1 values (1); explain select benchmark(1000, (select a from t1 where a=sha(rand()))); diff --git a/mysql-test/t/derived.test b/mysql-test/t/derived.test index 0ef56191b7ca7488ee582e63456ff1d059e7d4d0..ddd2b36e78e441d3c6cbfbf22e3f2ed09bc8e978 100644 --- a/mysql-test/t/derived.test +++ b/mysql-test/t/derived.test @@ -188,7 +188,6 @@ INSERT INTO t3 VALUES (1000,0.00),(1001,0.25),(1002,0.50),(1003,0.75),(1008,1.00 select 497, TMP.ID, NULL from (select 497 as ID, MAX(t3.DATA) as DATA from t1 join t2 on (t1.ObjectID = t2.ID) join t3 on (t1.ObjectID = t3.ID) group by t2.ParID order by DATA DESC) as TMP; drop table t1, t2, t3; - # # explain derived # @@ -206,3 +205,11 @@ insert into t2 values (1,7),(2,7); explain select a from t2 where a>1; explain select a from (select a from t2 where a>1) tt; drop table t2; + +# +# select list counter +# +CREATE TABLE `t1` ( `itemid` int(11) NOT NULL default '0', `grpid` varchar(15) NOT NULL default '', `vendor` int(11) NOT NULL default '0', `date_` date NOT NULL default '0000-00-00', `price` decimal(12,2) NOT NULL default '0.00', PRIMARY KEY (`itemid`,`grpid`,`vendor`,`date_`), KEY `itemid` (`itemid`,`vendor`), KEY `itemid_2` (`itemid`,`date_`)); +insert into t1 values (128, 'rozn', 2, now(), 10),(128, 'rozn', 1, now(), 10); +SELECT MIN(price) min, MAX(price) max, AVG(price) avg FROM (SELECT SUBSTRING( MAX(concat(date_,";",price)), 12) price FROM t1 WHERE itemid=128 AND grpid='rozn' GROUP BY itemid, grpid, vendor) lastprices; +DROP TABLE t1; diff --git a/mysql-test/t/subselect.test b/mysql-test/t/subselect.test index 05d04af2a7aa53dabb5d05a24555d589ce035f6b..6d766f8f8f8feb48b71ef351be92cdae745ecf1b 100644 --- a/mysql-test/t/subselect.test +++ b/mysql-test/t/subselect.test @@ -1072,7 +1072,23 @@ drop table t1; create table t1(val varchar(10)); insert into t1 values ('aaa'), ('bbb'),('eee'),('mmm'),('ppp'); select count(*) from t1 as w1 where w1.val in (select w2.val from t1 as w2 where w2.val like 'm%') and w1.val in (select w3.val from t1 as w3 where w3.val like 'e%'); -drop table if exists t1; +drop table t1; + +# +# ref_or_null replacing with ref +# +create table t1 (id int not null, text varchar(20) not null default '', primary key (id)); +insert into t1 (id, text) values (1, 'text1'), (2, 'text2'), (3, 'text3'), (4, 'text4'), (5, 'text5'), (6, 'text6'), (7, 'text7'), (8, 'text8'), (9, 'text9'), (10, 'text10'), (11, 'text11'), (12, 'text12'); +select * from t1 where id not in (select id from t1 where id < 8); +select * from t1 as tt where not exists (select id from t1 where id < 8 and (id = tt.id or id is null) having id is not null); +explain extended select * from t1 where id not in (select id from t1 where id < 8); +explain extended select * from t1 as tt where not exists (select id from t1 where id < 8 and (id = tt.id or id is null) having id is not null); +insert into t1 (id, text) values (1000, 'text1000'), (1001, 'text1001'); +create table t2 (id int not null, text varchar(20) not null default '', primary key (id)); +insert into t2 (id, text) values (1, 'text1'), (2, 'text2'), (3, 'text3'), (4, 'text4'), (5, 'text5'), (6, 'text6'), (7, 'text7'), (8, 'text8'), (9, 'text9'), (10, 'text10'), (11, 'text1'), (12, 'text2'), (13, 'text3'), (14, 'text4'), (15, 'text5'), (16, 'text6'), (17, 'text7'), (18, 'text8'), (19, 'text9'), (20, 'text10'),(21, 'text1'), (22, 'text2'), (23, 'text3'), (24, 'text4'), (25, 'text5'), (26, 'text6'), (27, 'text7'), (28, 'text8'), (29, 'text9'), (30, 'text10'), (31, 'text1'), (32, 'text2'), (33, 'text3'), (34, 'text4'), (35, 'text5'), (36, 'text6'), (37, 'text7'), (38, 'text8'), (39, 'text9'), (40, 'text10'), (41, 'text1'), (42, 'text2'), (43, 'text3'), (44, 'text4'), (45, 'text5'), (46, 'text6'), (47, 'text7'), (48, 'text8'), (49, 'text9'), (50, 'text10'); +select * from t1 a left join t2 b on (a.id=b.id or b.id is null) join t1 c on (if(isnull(b.id), 1000, b.id)=c.id); +explain extended select * from t1 a left join t2 b on (a.id=b.id or b.id is null) join t1 c on (if(isnull(b.id), 1000, b.id)=c.id); +drop table t1,t2; # # Static tables & rund() in subqueries diff --git a/sql/item_subselect.cc b/sql/item_subselect.cc index c5fdd79279da1ee1005d409cd6896ad20f7fa777..deb1ebabef9078216198e0695178f2538e0169cf 100644 --- a/sql/item_subselect.cc +++ b/sql/item_subselect.cc @@ -741,9 +741,9 @@ Item_in_subselect::single_value_transformer(JOIN *join, select_lex->ref_pointer_array[0]= select_lex->item_list.head(); if (select_lex->table_list.elements) { - Item *having= item, *isnull= item; + Item *having= item, *orig_item= item; item= func->create(expr, item); - if (!abort_on_null) + if (!abort_on_null && orig_item->maybe_null) { having= new Item_is_not_null_test(this, having); /* @@ -763,7 +763,7 @@ Item_in_subselect::single_value_transformer(JOIN *join, } select_lex->having_fix_field= 0; item= new Item_cond_or(item, - new Item_func_isnull(isnull)); + new Item_func_isnull(orig_item)); } item->name= (char *)in_additional_cond; /* diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 462a3a7b8cb05c73a8a93bf8994d6b33ed172851..e49aff6d82ccc090898aa8064622fd1bbbf7a3d5 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -3268,8 +3268,12 @@ static bool create_ref_for_key(JOIN *join, JOIN_TAB *j, KEYUSE *org_keyuse, keyuse,join->const_table_map, &keyinfo->key_part[i], (char*) key_buff,maybe_null); - /* Remmeber if we are going to use REF_OR_NULL */ - if (keyuse->optimize & KEY_OPTIMIZE_REF_OR_NULL) + /* + Remeber if we are going to use REF_OR_NULL + But only if field _really_ can be null i.e. we force JT_REF + instead of JT_REF_OR_NULL in case if field can't be null + */ + if ((keyuse->optimize & KEY_OPTIMIZE_REF_OR_NULL) && maybe_null) null_ref_key= key_buff; key_buff+=keyinfo->key_part[i].store_length; } diff --git a/sql/sql_yacc.yy b/sql/sql_yacc.yy index 0f9147b7834214d87d73ea123c4e09a4e0fb6ba9..dc7d3d5511099be51c69437d6e2d03282bc37aa6 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -3249,8 +3249,13 @@ select_derived: YYABORT; mysql_init_select(lex); lex->current_select->linkage= DERIVED_TABLE_TYPE; + lex->current_select->parsing_place= SELECT_LEX_NODE::SELECT_LIST; + } + select_options select_item_list + { + Select->parsing_place= SELECT_LEX_NODE::NO_MATTER; } - select_options select_item_list opt_select_from union_opt + opt_select_from union_opt ; opt_outer: