From ecfaa7522182a5dc257d8fbe3815d499946189ae Mon Sep 17 00:00:00 2001 From: unknown Date: Mon, 2 Feb 2004 02:23:53 +0200 Subject: [PATCH 1/4] avoid null check on fields where NULL is impossible (BUG#2393) mysql-test/r/subselect.result: BUG#2393 test suite test ref replaced ref_of_null joining mysql-test/t/subselect.test: BUG#2393 test suite test ref replaced ref_of_null joining sql/item_subselect.cc: avoid null check on fields where NULL is impossible sql/sql_select.cc: convert JT_REF_OR_NULL to JT_REF in case of impossible NULL and protect buffer of rewriting through join_tab->null_ref_key --- mysql-test/r/subselect.result | 56 +++++++++++++++++++++++++++++++++++ mysql-test/t/subselect.test | 16 ++++++++++ sql/item_subselect.cc | 6 ++-- sql/sql_select.cc | 8 +++-- 4 files changed, 81 insertions(+), 5 deletions(-) diff --git a/mysql-test/r/subselect.result b/mysql-test/r/subselect.result index c5050cf5f27..6ce758c88d4 100644 --- a/mysql-test/r/subselect.result +++ b/mysql-test/r/subselect.result @@ -1625,3 +1625,59 @@ PIPPO 1 NULL DROP TABLE t1, t2; +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((test.t1.id,(((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 1275 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; diff --git a/mysql-test/t/subselect.test b/mysql-test/t/subselect.test index c4392186055..12a819c609e 100644 --- a/mysql-test/t/subselect.test +++ b/mysql-test/t/subselect.test @@ -1075,3 +1075,19 @@ s.id_cns = cns.id ORDER BY s.anno_dep DESC LIMIT 1) AS PIPPO FROM t2 AS cns; DROP TABLE t1, t2; + +# +# 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; diff --git a/sql/item_subselect.cc b/sql/item_subselect.cc index 518b712ad18..712c543814e 100644 --- a/sql/item_subselect.cc +++ b/sql/item_subselect.cc @@ -682,9 +682,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); join->having= (join->having ? @@ -699,7 +699,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; join->conds= and_items(join->conds, item); diff --git a/sql/sql_select.cc b/sql/sql_select.cc index 874a3b16312..1572a6d0a5b 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -3240,8 +3240,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) + /* + Remmeber 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; } From 16a810f0cb84c78ff365a0742729da6ea5fcff35 Mon Sep 17 00:00:00 2001 From: unknown Date: Mon, 2 Feb 2004 14:58:36 +0200 Subject: [PATCH 2/4] fixed parsing mode for derived tables (BUG#2421) mysql-test/r/derived.result: test of BUG#2421 mysql-test/t/derived.test: test of BUG#2421 sql/sql_yacc.yy: fixed parsing mode for derived tables --- mysql-test/r/derived.result | 6 ++++++ mysql-test/t/derived.test | 8 ++++++++ sql/sql_yacc.yy | 7 ++++++- 3 files changed, 20 insertions(+), 1 deletion(-) diff --git a/mysql-test/r/derived.result b/mysql-test/r/derived.result index 170c393524b..481a2a5cd72 100644 --- a/mysql-test/r/derived.result +++ b/mysql-test/r/derived.result @@ -298,3 +298,9 @@ 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; 497 ID NULL drop table t1, t2, t3; +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/t/derived.test b/mysql-test/t/derived.test index 154fc4b3834..95ad9daf91e 100644 --- a/mysql-test/t/derived.test +++ b/mysql-test/t/derived.test @@ -183,3 +183,11 @@ CREATE TABLE t3 ( INSERT INTO t3 VALUES (1000,0.00),(1001,0.25),(1002,0.50),(1003,0.75),(1008,1.00),(1009,1.25),(1010,1.50),(1011,1.75); 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; + +# +# 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/sql/sql_yacc.yy b/sql/sql_yacc.yy index f04cc9ec1dc..682ca64f09b 100644 --- a/sql/sql_yacc.yy +++ b/sql/sql_yacc.yy @@ -3253,8 +3253,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 opt_select_from union_opt + select_options select_item_list + { + Select->parsing_place= SELECT_LEX_NODE::NO_MATTER; + } + opt_select_from union_opt ; opt_outer: From 4818c2557bd03c2cfe711ccd21948fa50c2e6b9e Mon Sep 17 00:00:00 2001 From: unknown Date: Mon, 15 Mar 2004 15:38:53 +0200 Subject: [PATCH 3/4] after review fixes --- sql/sql_select.cc | 4 ++-- 1 file changed, 2 insertions(+), 2 deletions(-) diff --git a/sql/sql_select.cc b/sql/sql_select.cc index cf1dea8e85a..17528bde693 100644 --- a/sql/sql_select.cc +++ b/sql/sql_select.cc @@ -3267,11 +3267,11 @@ static bool create_ref_for_key(JOIN *join, JOIN_TAB *j, KEYUSE *org_keyuse, &keyinfo->key_part[i], (char*) key_buff,maybe_null); /* - Remmeber if we are going to use 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) + if ((keyuse->optimize & KEY_OPTIMIZE_REF_OR_NULL) && maybe_null) null_ref_key= key_buff; key_buff+=keyinfo->key_part[i].store_length; } From 9d8dee212280813f866591b5c19efa63dfb6578f Mon Sep 17 00:00:00 2001 From: unknown Date: Tue, 16 Mar 2004 16:30:10 +0200 Subject: [PATCH 4/4] after merge fix mysql-test/r/subselect.result: changes in plans because we do not check nulls where nuul is impossible changed warning number --- mysql-test/r/subselect.result | 10 +++++----- 1 file changed, 5 insertions(+), 5 deletions(-) diff --git a/mysql-test/r/subselect.result b/mysql-test/r/subselect.result index 11290612a3c..e402d39ae97 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 (0,(select 1 AS `Not_used` from test.t1 a where isnull(1) having (1) limit 1)) AS `0 IN (SELECT 1 FROM t1 a)` +Note 1003 select high_priority (0,(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 (0,(select 1 AS `Not_used` from test.t1 a where isnull(1) having (1) limit 1)) AS `0 IN (SELECT 1 FROM t1 a)` +Note 1003 select high_priority (0,(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', @@ -1657,7 +1657,7 @@ 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 1275 Field or reference 'tt.id' of SELECT #2 was resolved in SELECT #1 +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));