mirror of
https://github.com/MariaDB/server.git
synced 2025-01-28 01:34:17 +01:00
WL#1724 "Min/Max Optimization for Queries with Group By Clause"
- after-review changes - merged with the source tree from 204-08-27 mysql-test/r/distinct.result: Different plans due to group-by optimization. sql/ha_myisam.cc: More general interface to key_copy. sql/handler.cc: More general interface to key_copy. sql/item.cc: New method to collect all Item_field objects. Used by Item::walk. sql/item.h: Several methods to collect different kinds of items from expression trees. Used by Item::walk. sql/item_sum.cc: Added helper to collect Item_sum objects. sql/item_sum.h: Methods to collect and test Item_sum objects. sql/key.cc: More general interface to key_copy and key_restore. sql/mysql_priv.h: More general interface to key_copy and key_restore. sql/opt_range.cc: Complete implementaion of WL#1724 "Min/Max Optimization for Queries with Group By Clause". sql/opt_range.h: Complete implementaion of WL#1724 "Min/Max Optimization for Queries with Group By Clause". sql/opt_sum.cc: simple_pred is re-used in opt_range.cc sql/sql_acl.cc: More general interface to key_copy and key_restore. sql/sql_handler.cc: More general interface to key_copy. sql/sql_insert.cc: More general interface to key_copy. sql/sql_select.cc: Changes to hook the new QUICK_GROUP_MIN_MAX_SELECT due to two differences from all other quick selects: 1) This quick select may be created (and used) even if there is no WHERE clause. Several places assumed that a QUICK_SELECT is constructed only if there is a WHERE clause, which had to be changed so that QUICK_GROUP_MIN_MAX can be used. 2) Unlike all other quick selects, this QUICK_GROUP_MIN_MAX_SELECT operates for GROUP BY queries. Since for the caller the quick select already produces one result tuple per group, there is no need to call end_send_group, instead we have to call end_send as for a regular quick select. sql/sql_select.h: simple_pred is re-used in opt_range.cc
This commit is contained in:
parent
7bba8128ed
commit
d945033292
19 changed files with 5077 additions and 204 deletions
|
@ -200,19 +200,19 @@ select distinct 1 from t1,t3 where t1.a=t3.a;
|
|||
1
|
||||
explain SELECT distinct t1.a from t1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 index NULL PRIMARY 4 NULL 4 Using index
|
||||
1 SIMPLE t1 range NULL PRIMARY 4 NULL 5 Using index for group-by
|
||||
explain SELECT distinct t1.a from t1 order by a desc;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 index NULL PRIMARY 4 NULL 4 Using index
|
||||
1 SIMPLE t1 range NULL PRIMARY 4 NULL 5 Using index for group-by; Using temporary; Using filesort
|
||||
explain SELECT t1.a from t1 group by a order by a desc;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 index NULL PRIMARY 4 NULL 4 Using index
|
||||
1 SIMPLE t1 range NULL PRIMARY 4 NULL 5 Using index for group-by; Using temporary; Using filesort
|
||||
explain SELECT distinct t1.a from t1 order by a desc limit 1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 index NULL PRIMARY 4 NULL 4 Using index
|
||||
1 SIMPLE t1 index NULL PRIMARY 4 NULL 5 Using index
|
||||
explain SELECT distinct a from t3 order by a desc limit 2;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t3 index NULL a 5 NULL 204 Using index
|
||||
1 SIMPLE t3 index NULL a 5 NULL 10 Using index
|
||||
explain SELECT distinct a,b from t3 order by a+1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t3 ALL NULL NULL NULL NULL 204 Using temporary; Using filesort
|
||||
|
|
1893
mysql-test/r/group_min_max.result
Normal file
1893
mysql-test/r/group_min_max.result
Normal file
File diff suppressed because it is too large
Load diff
573
mysql-test/t/group_min_max.test
Normal file
573
mysql-test/t/group_min_max.test
Normal file
|
@ -0,0 +1,573 @@
|
|||
#
|
||||
# Test file for WL#1724 (Min/Max Optimization for Queries with Group By Clause).
|
||||
# The queries in this file test query execution via QUICK_GROUP_MIN_MAX_SELECT.
|
||||
#
|
||||
|
||||
|
||||
--disable_warnings
|
||||
drop table if exists t1;
|
||||
--enable_warnings
|
||||
|
||||
create table t1 (
|
||||
a1 char(64), a2 char(64), b char(16), c char(16) not null, d char(16), dummy char(64) default ' '
|
||||
);
|
||||
|
||||
insert into t1 (a1, a2, b, c, d) values
|
||||
('a','a','a','a111','xy1'),('a','a','a','b111','xy2'),('a','a','a','c111','xy3'),('a','a','a','d111','xy4'),
|
||||
('a','a','b','e112','xy1'),('a','a','b','f112','xy2'),('a','a','b','g112','xy3'),('a','a','b','h112','xy4'),
|
||||
('a','b','a','i121','xy1'),('a','b','a','j121','xy2'),('a','b','a','k121','xy3'),('a','b','a','l121','xy4'),
|
||||
('a','b','b','m122','xy1'),('a','b','b','n122','xy2'),('a','b','b','o122','xy3'),('a','b','b','p122','xy4'),
|
||||
('b','a','a','a211','xy1'),('b','a','a','b211','xy2'),('b','a','a','c211','xy3'),('b','a','a','d211','xy4'),
|
||||
('b','a','b','e212','xy1'),('b','a','b','f212','xy2'),('b','a','b','g212','xy3'),('b','a','b','h212','xy4'),
|
||||
('b','b','a','i221','xy1'),('b','b','a','j221','xy2'),('b','b','a','k221','xy3'),('b','b','a','l221','xy4'),
|
||||
('b','b','b','m222','xy1'),('b','b','b','n222','xy2'),('b','b','b','o222','xy3'),('b','b','b','p222','xy4'),
|
||||
('c','a','a','a311','xy1'),('c','a','a','b311','xy2'),('c','a','a','c311','xy3'),('c','a','a','d311','xy4'),
|
||||
('c','a','b','e312','xy1'),('c','a','b','f312','xy2'),('c','a','b','g312','xy3'),('c','a','b','h312','xy4'),
|
||||
('c','b','a','i321','xy1'),('c','b','a','j321','xy2'),('c','b','a','k321','xy3'),('c','b','a','l321','xy4'),
|
||||
('c','b','b','m322','xy1'),('c','b','b','n322','xy2'),('c','b','b','o322','xy3'),('c','b','b','p322','xy4'),
|
||||
('d','a','a','a411','xy1'),('d','a','a','b411','xy2'),('d','a','a','c411','xy3'),('d','a','a','d411','xy4'),
|
||||
('d','a','b','e412','xy1'),('d','a','b','f412','xy2'),('d','a','b','g412','xy3'),('d','a','b','h412','xy4'),
|
||||
('d','b','a','i421','xy1'),('d','b','a','j421','xy2'),('d','b','a','k421','xy3'),('d','b','a','l421','xy4'),
|
||||
('d','b','b','m422','xy1'),('d','b','b','n422','xy2'),('d','b','b','o422','xy3'),('d','b','b','p422','xy4'),
|
||||
('a','a','a','a111','xy1'),('a','a','a','b111','xy2'),('a','a','a','c111','xy3'),('a','a','a','d111','xy4'),
|
||||
('a','a','b','e112','xy1'),('a','a','b','f112','xy2'),('a','a','b','g112','xy3'),('a','a','b','h112','xy4'),
|
||||
('a','b','a','i121','xy1'),('a','b','a','j121','xy2'),('a','b','a','k121','xy3'),('a','b','a','l121','xy4'),
|
||||
('a','b','b','m122','xy1'),('a','b','b','n122','xy2'),('a','b','b','o122','xy3'),('a','b','b','p122','xy4'),
|
||||
('b','a','a','a211','xy1'),('b','a','a','b211','xy2'),('b','a','a','c211','xy3'),('b','a','a','d211','xy4'),
|
||||
('b','a','b','e212','xy1'),('b','a','b','f212','xy2'),('b','a','b','g212','xy3'),('b','a','b','h212','xy4'),
|
||||
('b','b','a','i221','xy1'),('b','b','a','j221','xy2'),('b','b','a','k221','xy3'),('b','b','a','l221','xy4'),
|
||||
('b','b','b','m222','xy1'),('b','b','b','n222','xy2'),('b','b','b','o222','xy3'),('b','b','b','p222','xy4'),
|
||||
('c','a','a','a311','xy1'),('c','a','a','b311','xy2'),('c','a','a','c311','xy3'),('c','a','a','d311','xy4'),
|
||||
('c','a','b','e312','xy1'),('c','a','b','f312','xy2'),('c','a','b','g312','xy3'),('c','a','b','h312','xy4'),
|
||||
('c','b','a','i321','xy1'),('c','b','a','j321','xy2'),('c','b','a','k321','xy3'),('c','b','a','l321','xy4'),
|
||||
('c','b','b','m322','xy1'),('c','b','b','n322','xy2'),('c','b','b','o322','xy3'),('c','b','b','p322','xy4'),
|
||||
('d','a','a','a411','xy1'),('d','a','a','b411','xy2'),('d','a','a','c411','xy3'),('d','a','a','d411','xy4'),
|
||||
('d','a','b','e412','xy1'),('d','a','b','f412','xy2'),('d','a','b','g412','xy3'),('d','a','b','h412','xy4'),
|
||||
('d','b','a','i421','xy1'),('d','b','a','j421','xy2'),('d','b','a','k421','xy3'),('d','b','a','l421','xy4'),
|
||||
('d','b','b','m422','xy1'),('d','b','b','n422','xy2'),('d','b','b','o422','xy3'),('d','b','b','p422','xy4');
|
||||
|
||||
create index idx_t1_0 on t1 (a1);
|
||||
create index idx_t1_1 on t1 (a1,a2,b,c);
|
||||
create index idx_t1_2 on t1 (a1,a2,b);
|
||||
analyze table t1;
|
||||
|
||||
-- t2 is the same as t1, but with some NULLs in the MIN/MAX column, and one more
|
||||
-- nullable attribute
|
||||
|
||||
--disable_warnings
|
||||
drop table if exists t2;
|
||||
--enable_warnings
|
||||
|
||||
create table t2 (
|
||||
a1 char(64), a2 char(64) not null, b char(16), c char(16), d char(16), dummy char(64) default ' '
|
||||
);
|
||||
insert into t2 select * from t1;
|
||||
-- add few rows with NULL's in the MIN/MAX column
|
||||
insert into t2 (a1, a2, b, c, d) values
|
||||
('a','a',NULL,'a777','xyz'),('a','a',NULL,'a888','xyz'),('a','a',NULL,'a999','xyz'),
|
||||
('a','a','a',NULL,'xyz'),
|
||||
('a','a','b',NULL,'xyz'),
|
||||
('a','b','a',NULL,'xyz'),
|
||||
('c','a',NULL,'c777','xyz'),('c','a',NULL,'c888','xyz'),('c','a',NULL,'c999','xyz'),
|
||||
('d','b','b',NULL,'xyz'),
|
||||
('e','a','a',NULL,'xyz'),('e','a','a',NULL,'xyz'),('e','a','a',NULL,'xyz'),('e','a','a',NULL,'xyz'),
|
||||
('e','a','b',NULL,'xyz'),('e','a','b',NULL,'xyz'),('e','a','b',NULL,'xyz'),('e','a','b',NULL,'xyz'),
|
||||
('a','a',NULL,'a777','xyz'),('a','a',NULL,'a888','xyz'),('a','a',NULL,'a999','xyz'),
|
||||
('a','a','a',NULL,'xyz'),
|
||||
('a','a','b',NULL,'xyz'),
|
||||
('a','b','a',NULL,'xyz'),
|
||||
('c','a',NULL,'c777','xyz'),('c','a',NULL,'c888','xyz'),('c','a',NULL,'c999','xyz'),
|
||||
('d','b','b',NULL,'xyz'),
|
||||
('e','a','a',NULL,'xyz'),('e','a','a',NULL,'xyz'),('e','a','a',NULL,'xyz'),('e','a','a',NULL,'xyz'),
|
||||
('e','a','b',NULL,'xyz'),('e','a','b',NULL,'xyz'),('e','a','b',NULL,'xyz'),('e','a','b',NULL,'xyz');
|
||||
|
||||
create index idx_t2_0 on t2 (a1);
|
||||
create index idx_t2_1 on t2 (a1,a2,b,c);
|
||||
create index idx_t2_2 on t2 (a1,a2,b);
|
||||
analyze table t2;
|
||||
|
||||
-- Table t3 is the same as t1, but with smaller column lenghts.
|
||||
-- This allows to test different branches of the cost computation procedure
|
||||
-- when the number of keys per block are less than the number of keys in the
|
||||
-- sub-groups formed by predicates over non-group attributes.
|
||||
|
||||
--disable_warnings
|
||||
drop table if exists t3;
|
||||
--enable_warnings
|
||||
|
||||
create table t3 (
|
||||
a1 char(1), a2 char(1), b char(1), c char(4) not null, d char(3), dummy char(1) default ' '
|
||||
);
|
||||
|
||||
insert into t3 (a1, a2, b, c, d) values
|
||||
('a','a','a','a111','xy1'),('a','a','a','b111','xy2'),('a','a','a','c111','xy3'),('a','a','a','d111','xy4'),
|
||||
('a','a','b','e112','xy1'),('a','a','b','f112','xy2'),('a','a','b','g112','xy3'),('a','a','b','h112','xy4'),
|
||||
('a','b','a','i121','xy1'),('a','b','a','j121','xy2'),('a','b','a','k121','xy3'),('a','b','a','l121','xy4'),
|
||||
('a','b','b','m122','xy1'),('a','b','b','n122','xy2'),('a','b','b','o122','xy3'),('a','b','b','p122','xy4'),
|
||||
('b','a','a','a211','xy1'),('b','a','a','b211','xy2'),('b','a','a','c211','xy3'),('b','a','a','d211','xy4'),
|
||||
('b','a','b','e212','xy1'),('b','a','b','f212','xy2'),('b','a','b','g212','xy3'),('b','a','b','h212','xy4'),
|
||||
('b','b','a','i221','xy1'),('b','b','a','j221','xy2'),('b','b','a','k221','xy3'),('b','b','a','l221','xy4'),
|
||||
('b','b','b','m222','xy1'),('b','b','b','n222','xy2'),('b','b','b','o222','xy3'),('b','b','b','p222','xy4'),
|
||||
('c','a','a','a311','xy1'),('c','a','a','b311','xy2'),('c','a','a','c311','xy3'),('c','a','a','d311','xy4'),
|
||||
('c','a','b','e312','xy1'),('c','a','b','f312','xy2'),('c','a','b','g312','xy3'),('c','a','b','h312','xy4'),
|
||||
('c','b','a','i321','xy1'),('c','b','a','j321','xy2'),('c','b','a','k321','xy3'),('c','b','a','l321','xy4'),
|
||||
('c','b','b','m322','xy1'),('c','b','b','n322','xy2'),('c','b','b','o322','xy3'),('c','b','b','p322','xy4');
|
||||
insert into t3 (a1, a2, b, c, d) values
|
||||
('a','a','a','a111','xy1'),('a','a','a','b111','xy2'),('a','a','a','c111','xy3'),('a','a','a','d111','xy4'),
|
||||
('a','a','b','e112','xy1'),('a','a','b','f112','xy2'),('a','a','b','g112','xy3'),('a','a','b','h112','xy4'),
|
||||
('a','b','a','i121','xy1'),('a','b','a','j121','xy2'),('a','b','a','k121','xy3'),('a','b','a','l121','xy4'),
|
||||
('a','b','b','m122','xy1'),('a','b','b','n122','xy2'),('a','b','b','o122','xy3'),('a','b','b','p122','xy4'),
|
||||
('b','a','a','a211','xy1'),('b','a','a','b211','xy2'),('b','a','a','c211','xy3'),('b','a','a','d211','xy4'),
|
||||
('b','a','b','e212','xy1'),('b','a','b','f212','xy2'),('b','a','b','g212','xy3'),('b','a','b','h212','xy4'),
|
||||
('b','b','a','i221','xy1'),('b','b','a','j221','xy2'),('b','b','a','k221','xy3'),('b','b','a','l221','xy4'),
|
||||
('b','b','b','m222','xy1'),('b','b','b','n222','xy2'),('b','b','b','o222','xy3'),('b','b','b','p222','xy4'),
|
||||
('c','a','a','a311','xy1'),('c','a','a','b311','xy2'),('c','a','a','c311','xy3'),('c','a','a','d311','xy4'),
|
||||
('c','a','b','e312','xy1'),('c','a','b','f312','xy2'),('c','a','b','g312','xy3'),('c','a','b','h312','xy4'),
|
||||
('c','b','a','i321','xy1'),('c','b','a','j321','xy2'),('c','b','a','k321','xy3'),('c','b','a','l321','xy4'),
|
||||
('c','b','b','m322','xy1'),('c','b','b','n322','xy2'),('c','b','b','o322','xy3'),('c','b','b','p322','xy4');
|
||||
insert into t3 (a1, a2, b, c, d) values
|
||||
('a','a','a','a111','xy1'),('a','a','a','b111','xy2'),('a','a','a','c111','xy3'),('a','a','a','d111','xy4'),
|
||||
('a','a','b','e112','xy1'),('a','a','b','f112','xy2'),('a','a','b','g112','xy3'),('a','a','b','h112','xy4'),
|
||||
('a','b','a','i121','xy1'),('a','b','a','j121','xy2'),('a','b','a','k121','xy3'),('a','b','a','l121','xy4'),
|
||||
('a','b','b','m122','xy1'),('a','b','b','n122','xy2'),('a','b','b','o122','xy3'),('a','b','b','p122','xy4'),
|
||||
('b','a','a','a211','xy1'),('b','a','a','b211','xy2'),('b','a','a','c211','xy3'),('b','a','a','d211','xy4'),
|
||||
('b','a','b','e212','xy1'),('b','a','b','f212','xy2'),('b','a','b','g212','xy3'),('b','a','b','h212','xy4'),
|
||||
('b','b','a','i221','xy1'),('b','b','a','j221','xy2'),('b','b','a','k221','xy3'),('b','b','a','l221','xy4'),
|
||||
('b','b','b','m222','xy1'),('b','b','b','n222','xy2'),('b','b','b','o222','xy3'),('b','b','b','p222','xy4'),
|
||||
('c','a','a','a311','xy1'),('c','a','a','b311','xy2'),('c','a','a','c311','xy3'),('c','a','a','d311','xy4'),
|
||||
('c','a','b','e312','xy1'),('c','a','b','f312','xy2'),('c','a','b','g312','xy3'),('c','a','b','h312','xy4'),
|
||||
('c','b','a','i321','xy1'),('c','b','a','j321','xy2'),('c','b','a','k321','xy3'),('c','b','a','l321','xy4'),
|
||||
('c','b','b','m322','xy1'),('c','b','b','n322','xy2'),('c','b','b','o322','xy3'),('c','b','b','p322','xy4');
|
||||
insert into t3 (a1, a2, b, c, d) values
|
||||
('a','a','a','a111','xy1'),('a','a','a','b111','xy2'),('a','a','a','c111','xy3'),('a','a','a','d111','xy4'),
|
||||
('a','a','b','e112','xy1'),('a','a','b','f112','xy2'),('a','a','b','g112','xy3'),('a','a','b','h112','xy4'),
|
||||
('a','b','a','i121','xy1'),('a','b','a','j121','xy2'),('a','b','a','k121','xy3'),('a','b','a','l121','xy4'),
|
||||
('a','b','b','m122','xy1'),('a','b','b','n122','xy2'),('a','b','b','o122','xy3'),('a','b','b','p122','xy4'),
|
||||
('b','a','a','a211','xy1'),('b','a','a','b211','xy2'),('b','a','a','c211','xy3'),('b','a','a','d211','xy4'),
|
||||
('b','a','b','e212','xy1'),('b','a','b','f212','xy2'),('b','a','b','g212','xy3'),('b','a','b','h212','xy4'),
|
||||
('b','b','a','i221','xy1'),('b','b','a','j221','xy2'),('b','b','a','k221','xy3'),('b','b','a','l221','xy4'),
|
||||
('b','b','b','m222','xy1'),('b','b','b','n222','xy2'),('b','b','b','o222','xy3'),('b','b','b','p222','xy4'),
|
||||
('c','a','a','a311','xy1'),('c','a','a','b311','xy2'),('c','a','a','c311','xy3'),('c','a','a','d311','xy4'),
|
||||
('c','a','b','e312','xy1'),('c','a','b','f312','xy2'),('c','a','b','g312','xy3'),('c','a','b','h312','xy4'),
|
||||
('c','b','a','i321','xy1'),('c','b','a','j321','xy2'),('c','b','a','k321','xy3'),('c','b','a','l321','xy4'),
|
||||
('c','b','b','m322','xy1'),('c','b','b','n322','xy2'),('c','b','b','o322','xy3'),('c','b','b','p322','xy4');
|
||||
|
||||
create index idx_t3_0 on t3 (a1);
|
||||
create index idx_t3_1 on t3 (a1,a2,b,c);
|
||||
create index idx_t3_2 on t3 (a1,a2,b);
|
||||
analyze table t3;
|
||||
|
||||
|
||||
--
|
||||
-- Queries without a WHERE clause. These queries do not use ranges.
|
||||
--
|
||||
|
||||
-- plans
|
||||
explain select a1, min(a2) from t1 group by a1;
|
||||
explain select a1, max(a2) from t1 group by a1;
|
||||
explain select a1, min(a2), max(a2) from t1 group by a1;
|
||||
explain select a1, a2, b, min(c), max(c) from t1 group by a1,a2,b;
|
||||
explain select a1,a2,b,max(c),min(c) from t1 group by a1,a2,b;
|
||||
explain select a1,a2,b,max(c),min(c) from t2 group by a1,a2,b;
|
||||
-- Select fields in different order
|
||||
explain select min(a2), a1, max(a2), min(a2), a1 from t1 group by a1;
|
||||
explain select a1, b, min(c), a1, max(c), b, a2, max(c), max(c) from t1 group by a1, a2, b;
|
||||
explain select min(a2) from t1 group by a1;
|
||||
explain select a2, min(c), max(c) from t1 group by a1,a2,b;
|
||||
|
||||
-- TODO: Queries with HAVING
|
||||
|
||||
-- queries
|
||||
select a1, min(a2) from t1 group by a1;
|
||||
select a1, max(a2) from t1 group by a1;
|
||||
select a1, min(a2), max(a2) from t1 group by a1;
|
||||
select a1, a2, b, min(c), max(c) from t1 group by a1,a2,b;
|
||||
select a1,a2,b,max(c),min(c) from t1 group by a1,a2,b;
|
||||
select a1,a2,b,max(c),min(c) from t2 group by a1,a2,b;
|
||||
-- Select fields in different order
|
||||
select min(a2), a1, max(a2), min(a2), a1 from t1 group by a1;
|
||||
select a1, b, min(c), a1, max(c), b, a2, max(c), max(c) from t1 group by a1, a2, b;
|
||||
select min(a2) from t1 group by a1;
|
||||
select a2, min(c), max(c) from t1 group by a1,a2,b;
|
||||
|
||||
-- TODO: Queries with HAVING
|
||||
|
||||
--
|
||||
-- Queries with a where clause
|
||||
--
|
||||
|
||||
-- A) Preds only over the group 'A' attributes
|
||||
-- plans
|
||||
explain select a1,a2,b,min(c),max(c) from t1 where a1 < 'd' group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t1 where a1 >= 'b' group by a1,a2,b;
|
||||
explain select a1,a2,b, max(c) from t1 where a1 >= 'c' or a1 < 'b' group by a1,a2,b;
|
||||
explain select a1, max(c) from t1 where a1 >= 'c' or a1 < 'b' group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t1 where a1 >= 'c' or a2 < 'b' group by a1,a2,b;
|
||||
explain select a1,a2,b, max(c) from t1 where a1 = 'z' or a1 = 'b' or a1 = 'd' group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t1 where a1 = 'z' or a1 = 'b' or a1 = 'd' group by a1,a2,b;
|
||||
explain select a1,a2,b, max(c) from t1 where (a1 = 'b' or a1 = 'd' or a1 = 'a' or a1 = 'c') and (a2 > 'a') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t1 where (a1 = 'b' or a1 = 'd' or a1 = 'a' or a1 = 'c') and (a2 > 'a') group by a1,a2,b;
|
||||
explain select a1,min(c),max(c) from t1 where a1 >= 'b' group by a1,a2,b;
|
||||
explain select a1, max(c) from t1 where a1 in ('a','b','d') group by a1,a2,b;
|
||||
|
||||
explain select a1,a2,b, max(c) from t2 where a1 < 'd' group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t2 where a1 < 'd' group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t2 where a1 >= 'b' group by a1,a2,b;
|
||||
explain select a1,a2,b, max(c) from t2 where a1 >= 'c' or a1 < 'b' group by a1,a2,b;
|
||||
explain select a1, max(c) from t2 where a1 >= 'c' or a1 < 'b' group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t2 where a1 >= 'c' or a2 < 'b' group by a1,a2,b;
|
||||
explain select a1,a2,b, max(c) from t2 where a1 = 'z' or a1 = 'b' or a1 = 'd' group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t2 where a1 = 'z' or a1 = 'b' or a1 = 'd' group by a1,a2,b;
|
||||
explain select a1,a2,b, max(c) from t2 where (a1 = 'b' or a1 = 'd' or a1 = 'a' or a1 = 'c') and (a2 > 'a') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t2 where (a1 = 'b' or a1 = 'd' or a1 = 'a' or a1 = 'c') and (a2 > 'a') group by a1,a2,b;
|
||||
explain select a1,min(c),max(c) from t2 where a1 >= 'b' group by a1,a2,b;
|
||||
explain select a1, max(c) from t2 where a1 in ('a','b','d') group by a1,a2,b;
|
||||
|
||||
-- queries
|
||||
select a1,a2,b,min(c),max(c) from t1 where a1 < 'd' group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t1 where a1 >= 'b' group by a1,a2,b;
|
||||
select a1,a2,b, max(c) from t1 where a1 >= 'c' or a1 < 'b' group by a1,a2,b;
|
||||
select a1, max(c) from t1 where a1 >= 'c' or a1 < 'b' group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t1 where a1 >= 'c' or a2 < 'b' group by a1,a2,b;
|
||||
select a1,a2,b, max(c) from t1 where a1 = 'z' or a1 = 'b' or a1 = 'd' group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t1 where a1 = 'z' or a1 = 'b' or a1 = 'd' group by a1,a2,b;
|
||||
select a1,a2,b, max(c) from t1 where (a1 = 'b' or a1 = 'd' or a1 = 'a' or a1 = 'c') and (a2 > 'a') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t1 where (a1 = 'b' or a1 = 'd' or a1 = 'a' or a1 = 'c') and (a2 > 'a') group by a1,a2,b;
|
||||
select a1,min(c),max(c) from t1 where a1 >= 'b' group by a1,a2,b;
|
||||
select a1, max(c) from t1 where a1 in ('a','b','d') group by a1,a2,b;
|
||||
|
||||
select a1,a2,b, max(c) from t2 where a1 < 'd' group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t2 where a1 < 'd' group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t2 where a1 >= 'b' group by a1,a2,b;
|
||||
select a1,a2,b, max(c) from t2 where a1 >= 'c' or a1 < 'b' group by a1,a2,b;
|
||||
select a1, max(c) from t2 where a1 >= 'c' or a1 < 'b' group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t2 where a1 >= 'c' or a2 < 'b' group by a1,a2,b;
|
||||
select a1,a2,b, max(c) from t2 where a1 = 'z' or a1 = 'b' or a1 = 'd' group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t2 where a1 = 'z' or a1 = 'b' or a1 = 'd' group by a1,a2,b;
|
||||
select a1,a2,b, max(c) from t2 where (a1 = 'b' or a1 = 'd' or a1 = 'a' or a1 = 'c') and (a2 > 'a') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t2 where (a1 = 'b' or a1 = 'd' or a1 = 'a' or a1 = 'c') and (a2 > 'a') group by a1,a2,b;
|
||||
select a1,min(c),max(c) from t2 where a1 >= 'b' group by a1,a2,b;
|
||||
select a1, max(c) from t2 where a1 in ('a','b','d') group by a1,a2,b;
|
||||
|
||||
-- B) Equalities only over the non-group 'B' attributes
|
||||
-- plans
|
||||
explain select a1,a2,b,max(c),min(c) from t1 where (a2 = 'a') and (b = 'b') group by a1;
|
||||
explain select a1,max(c),min(c) from t1 where (a2 = 'a') and (b = 'b') group by a1;
|
||||
explain select a1,a2,b, max(c) from t1 where (b = 'b') group by a1,a2;
|
||||
explain select a1,a2,b,min(c),max(c) from t1 where (b = 'b') group by a1,a2;
|
||||
explain select a1,a2, max(c) from t1 where (b = 'b') group by a1,a2;
|
||||
|
||||
explain select a1,a2,b,max(c),min(c) from t2 where (a2 = 'a') and (b = 'b') group by a1;
|
||||
explain select a1,max(c),min(c) from t2 where (a2 = 'a') and (b = 'b') group by a1;
|
||||
explain select a1,a2,b, max(c) from t2 where (b = 'b') group by a1,a2;
|
||||
explain select a1,a2,b,min(c),max(c) from t2 where (b = 'b') group by a1,a2;
|
||||
explain select a1,a2, max(c) from t2 where (b = 'b') group by a1,a2;
|
||||
|
||||
-- these queries test case 2) in TRP_GROUP_MIN_MAX::update_cost()
|
||||
explain select a1,a2,b,max(c),min(c) from t3 where (a2 = 'a') and (b = 'b') group by a1;
|
||||
explain select a1,max(c),min(c) from t3 where (a2 = 'a') and (b = 'b') group by a1;
|
||||
|
||||
-- queries
|
||||
select a1,a2,b,max(c),min(c) from t1 where (a2 = 'a') and (b = 'b') group by a1;
|
||||
select a1,max(c),min(c) from t1 where (a2 = 'a') and (b = 'b') group by a1;
|
||||
select a1,a2,b, max(c) from t1 where (b = 'b') group by a1,a2;
|
||||
select a1,a2,b,min(c),max(c) from t1 where (b = 'b') group by a1,a2;
|
||||
select a1,a2, max(c) from t1 where (b = 'b') group by a1,a2;
|
||||
|
||||
select a1,a2,b,max(c),min(c) from t2 where (a2 = 'a') and (b = 'b') group by a1;
|
||||
select a1,max(c),min(c) from t2 where (a2 = 'a') and (b = 'b') group by a1;
|
||||
select a1,a2,b, max(c) from t2 where (b = 'b') group by a1,a2;
|
||||
select a1,a2,b,min(c),max(c) from t2 where (b = 'b') group by a1,a2;
|
||||
select a1,a2, max(c) from t2 where (b = 'b') group by a1,a2;
|
||||
|
||||
-- these queries test case 2) in TRP_GROUP_MIN_MAX::update_cost()
|
||||
select a1,a2,b,max(c),min(c) from t3 where (a2 = 'a') and (b = 'b') group by a1;
|
||||
select a1,max(c),min(c) from t3 where (a2 = 'a') and (b = 'b') group by a1;
|
||||
|
||||
|
||||
-- IS NULL (makes sense for t2 only)
|
||||
-- plans
|
||||
explain select a1,a2,b,min(c) from t2 where (a2 = 'a') and b is NULL group by a1;
|
||||
explain select a1,a2,b,max(c) from t2 where (a2 = 'a') and b is NULL group by a1;
|
||||
explain select a1,a2,b,min(c) from t2 where b is NULL group by a1,a2;
|
||||
explain select a1,a2,b,max(c) from t2 where b is NULL group by a1,a2;
|
||||
explain select a1,a2,b,min(c),max(c) from t2 where b is NULL group by a1,a2;
|
||||
explain select a1,a2,b,min(c),max(c) from t2 where b is NULL group by a1,a2;
|
||||
-- queries
|
||||
select a1,a2,b,min(c) from t2 where (a2 = 'a') and b is NULL group by a1;
|
||||
select a1,a2,b,max(c) from t2 where (a2 = 'a') and b is NULL group by a1;
|
||||
select a1,a2,b,min(c) from t2 where b is NULL group by a1,a2;
|
||||
select a1,a2,b,max(c) from t2 where b is NULL group by a1,a2;
|
||||
select a1,a2,b,min(c),max(c) from t2 where b is NULL group by a1,a2;
|
||||
select a1,a2,b,min(c),max(c) from t2 where b is NULL group by a1,a2;
|
||||
-- TODO: IS NOT NULL ?
|
||||
|
||||
-- C) Range predicates for the MIN/MAX attribute
|
||||
-- plans
|
||||
explain select a1,a2,b, max(c) from t1 where (c > 'b1') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t1 where (c > 'b1') group by a1,a2,b;
|
||||
explain select a1,a2,b, max(c) from t1 where (c > 'f123') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t1 where (c > 'f123') group by a1,a2,b;
|
||||
explain select a1,a2,b, max(c) from t1 where (c < 'a0') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t1 where (c < 'a0') group by a1,a2,b;
|
||||
explain select a1,a2,b, max(c) from t1 where (c < 'k321') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t1 where (c < 'k321') group by a1,a2,b;
|
||||
explain select a1,a2,b, max(c) from t1 where (c < 'a0') or (c > 'b1') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t1 where (c < 'a0') or (c > 'b1') group by a1,a2,b;
|
||||
explain select a1,a2,b, max(c) from t1 where (c > 'b1') or (c <= 'g1') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t1 where (c > 'b1') or (c <= 'g1') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t1 where (c > 'b111') and (c <= 'g112') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t1 where (c < 'c5') or (c = 'g412') or (c = 'k421') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t1 where ((c > 'b111') and (c <= 'g112')) or ((c > 'd000') and (c <= 'i110')) group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t1 where (c between 'b111' and 'g112') or (c between 'd000' and 'i110') group by a1,a2,b;
|
||||
|
||||
explain select a1,a2,b, max(c) from t2 where (c > 'b1') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t2 where (c > 'b1') group by a1,a2,b;
|
||||
explain select a1,a2,b, max(c) from t2 where (c > 'f123') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t2 where (c > 'f123') group by a1,a2,b;
|
||||
explain select a1,a2,b, max(c) from t2 where (c < 'a0') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t2 where (c < 'a0') group by a1,a2,b;
|
||||
explain select a1,a2,b, max(c) from t2 where (c < 'k321') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t2 where (c < 'k321') group by a1,a2,b;
|
||||
explain select a1,a2,b, max(c) from t2 where (c < 'a0') or (c > 'b1') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t2 where (c < 'a0') or (c > 'b1') group by a1,a2,b;
|
||||
explain select a1,a2,b, max(c) from t2 where (c > 'b1') or (c <= 'g1') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t2 where (c > 'b1') or (c <= 'g1') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t2 where (c > 'b111') and (c <= 'g112') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t2 where (c < 'c5') or (c = 'g412') or (c = 'k421') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t2 where ((c > 'b111') and (c <= 'g112')) or ((c > 'd000') and (c <= 'i110')) group by a1,a2,b;
|
||||
|
||||
-- queries
|
||||
select a1,a2,b, max(c) from t1 where (c > 'b1') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t1 where (c > 'b1') group by a1,a2,b;
|
||||
select a1,a2,b, max(c) from t1 where (c > 'f123') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t1 where (c > 'f123') group by a1,a2,b;
|
||||
select a1,a2,b, max(c) from t1 where (c < 'a0') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t1 where (c < 'a0') group by a1,a2,b;
|
||||
select a1,a2,b, max(c) from t1 where (c < 'k321') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t1 where (c < 'k321') group by a1,a2,b;
|
||||
select a1,a2,b, max(c) from t1 where (c < 'a0') or (c > 'b1') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t1 where (c < 'a0') or (c > 'b1') group by a1,a2,b;
|
||||
select a1,a2,b, max(c) from t1 where (c > 'b1') or (c <= 'g1') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t1 where (c > 'b1') or (c <= 'g1') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t1 where (c > 'b111') and (c <= 'g112') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t1 where (c < 'c5') or (c = 'g412') or (c = 'k421') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t1 where ((c > 'b111') and (c <= 'g112')) or ((c > 'd000') and (c <= 'i110')) group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t1 where (c between 'b111' and 'g112') or (c between 'd000' and 'i110') group by a1,a2,b;
|
||||
|
||||
select a1,a2,b, max(c) from t2 where (c > 'b1') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t2 where (c > 'b1') group by a1,a2,b;
|
||||
select a1,a2,b, max(c) from t2 where (c > 'f123') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t2 where (c > 'f123') group by a1,a2,b;
|
||||
select a1,a2,b, max(c) from t2 where (c < 'a0') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t2 where (c < 'a0') group by a1,a2,b;
|
||||
select a1,a2,b, max(c) from t2 where (c < 'k321') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t2 where (c < 'k321') group by a1,a2,b;
|
||||
select a1,a2,b, max(c) from t2 where (c < 'a0') or (c > 'b1') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t2 where (c < 'a0') or (c > 'b1') group by a1,a2,b;
|
||||
select a1,a2,b, max(c) from t2 where (c > 'b1') or (c <= 'g1') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t2 where (c > 'b1') or (c <= 'g1') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t2 where (c > 'b111') and (c <= 'g112') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t2 where (c < 'c5') or (c = 'g412') or (c = 'k421') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t2 where ((c > 'b111') and (c <= 'g112')) or ((c > 'd000') and (c <= 'i110')) group by a1,a2,b;
|
||||
|
||||
-- A,B,C) Predicates referencing mixed classes of attributes
|
||||
-- plans
|
||||
explain select a1,a2,b,min(c),max(c) from t1 where (a1 >= 'c' or a2 < 'b') and (b > 'a') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t1 where (a1 >= 'c' or a2 < 'b') and (c > 'b111') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t1 where (a2 >= 'b') and (b = 'a') and (c > 'b111') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c) from t1 where ((a1 > 'a') or (a1 < '9')) and ((a2 >= 'b') and (a2 < 'z')) and (b = 'a') and ((c < 'h112') or (c = 'j121') or (c > 'k121' and c < 'm122') or (c > 'o122')) group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c) from t1 where ((a1 > 'a') or (a1 < '9')) and ((a2 >= 'b') and (a2 < 'z')) and (b = 'a') and ((c = 'j121') or (c > 'k121' and c < 'm122') or (c > 'o122') or (c < 'h112') or (c = 'c111')) group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c) from t1 where (a1 > 'a') and (a2 > 'a') and (b = 'c') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c) from t1 where (ord(a1) > 97) and (ord(a2) + ord(a1) > 194) and (b = 'c') group by a1,a2,b;
|
||||
|
||||
explain select a1,a2,b,min(c),max(c) from t2 where (a1 >= 'c' or a2 < 'b') and (b > 'a') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t2 where (a1 >= 'c' or a2 < 'b') and (c > 'b111') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c),max(c) from t2 where (a2 >= 'b') and (b = 'a') and (c > 'b111') group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c) from t2 where ((a1 > 'a') or (a1 < '9')) and ((a2 >= 'b') and (a2 < 'z')) and (b = 'a') and ((c < 'h112') or (c = 'j121') or (c > 'k121' and c < 'm122') or (c > 'o122')) group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c) from t2 where ((a1 > 'a') or (a1 < '9')) and ((a2 >= 'b') and (a2 < 'z')) and (b = 'a') and ((c = 'j121') or (c > 'k121' and c < 'm122') or (c > 'o122') or (c < 'h112') or (c = 'c111')) group by a1,a2,b;
|
||||
explain select a1,a2,b,min(c) from t2 where (a1 > 'a') and (a2 > 'a') and (b = 'c') group by a1,a2,b;
|
||||
|
||||
-- queries
|
||||
select a1,a2,b,min(c),max(c) from t1 where (a1 >= 'c' or a2 < 'b') and (b > 'a') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t1 where (a1 >= 'c' or a2 < 'b') and (c > 'b111') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t1 where (a2 >= 'b') and (b = 'a') and (c > 'b111') group by a1,a2,b;
|
||||
select a1,a2,b,min(c) from t1 where ((a1 > 'a') or (a1 < '9')) and ((a2 >= 'b') and (a2 < 'z')) and (b = 'a') and ((c < 'h112') or (c = 'j121') or (c > 'k121' and c < 'm122') or (c > 'o122')) group by a1,a2,b;
|
||||
select a1,a2,b,min(c) from t1 where ((a1 > 'a') or (a1 < '9')) and ((a2 >= 'b') and (a2 < 'z')) and (b = 'a') and ((c = 'j121') or (c > 'k121' and c < 'm122') or (c > 'o122') or (c < 'h112') or (c = 'c111')) group by a1,a2,b;
|
||||
select a1,a2,b,min(c) from t1 where (a1 > 'a') and (a2 > 'a') and (b = 'c') group by a1,a2,b;
|
||||
select a1,a2,b,min(c) from t1 where (ord(a1) > 97) and (ord(a2) + ord(a1) > 194) and (b = 'c') group by a1,a2,b;
|
||||
|
||||
select a1,a2,b,min(c),max(c) from t2 where (a1 >= 'c' or a2 < 'b') and (b > 'a') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t2 where (a1 >= 'c' or a2 < 'b') and (c > 'b111') group by a1,a2,b;
|
||||
select a1,a2,b,min(c),max(c) from t2 where (a2 >= 'b') and (b = 'a') and (c > 'b111') group by a1,a2,b;
|
||||
select a1,a2,b,min(c) from t2 where ((a1 > 'a') or (a1 < '9')) and ((a2 >= 'b') and (a2 < 'z')) and (b = 'a') and ((c < 'h112') or (c = 'j121') or (c > 'k121' and c < 'm122') or (c > 'o122')) group by a1,a2,b;
|
||||
select a1,a2,b,min(c) from t2 where ((a1 > 'a') or (a1 < '9')) and ((a2 >= 'b') and (a2 < 'z')) and (b = 'a') and ((c = 'j121') or (c > 'k121' and c < 'm122') or (c > 'o122') or (c < 'h112') or (c = 'c111')) group by a1,a2,b;
|
||||
select a1,a2,b,min(c) from t2 where (a1 > 'a') and (a2 > 'a') and (b = 'c') group by a1,a2,b;
|
||||
|
||||
|
||||
--
|
||||
-- GROUP BY queries without MIN/MAX
|
||||
--
|
||||
|
||||
-- plans
|
||||
explain select a1,a2,b from t1 where (a1 >= 'c' or a2 < 'b') and (b > 'a') group by a1,a2,b;
|
||||
explain select a1,a2,b from t1 where (a2 >= 'b') and (b = 'a') group by a1,a2,b;
|
||||
explain select a1,a2,b,c from t1 where (a2 >= 'b') and (b = 'a') and (c = 'i121') group by a1,a2,b;
|
||||
explain select a1,a2,b from t1 where (a1 > 'a') and (a2 > 'a') and (b = 'c') group by a1,a2,b;
|
||||
|
||||
explain select a1,a2,b from t2 where (a1 >= 'c' or a2 < 'b') and (b > 'a') group by a1,a2,b;
|
||||
explain select a1,a2,b from t2 where (a2 >= 'b') and (b = 'a') group by a1,a2,b;
|
||||
explain select a1,a2,b,c from t2 where (a2 >= 'b') and (b = 'a') and (c = 'i121') group by a1,a2,b;
|
||||
explain select a1,a2,b from t2 where (a1 > 'a') and (a2 > 'a') and (b = 'c') group by a1,a2,b;
|
||||
|
||||
-- queries
|
||||
select a1,a2,b from t1 where (a1 >= 'c' or a2 < 'b') and (b > 'a') group by a1,a2,b;
|
||||
select a1,a2,b from t1 where (a2 >= 'b') and (b = 'a') group by a1,a2,b;
|
||||
select a1,a2,b,c from t1 where (a2 >= 'b') and (b = 'a') and (c = 'i121') group by a1,a2,b;
|
||||
select a1,a2,b from t1 where (a1 > 'a') and (a2 > 'a') and (b = 'c') group by a1,a2,b;
|
||||
|
||||
select a1,a2,b from t2 where (a1 >= 'c' or a2 < 'b') and (b > 'a') group by a1,a2,b;
|
||||
select a1,a2,b from t2 where (a2 >= 'b') and (b = 'a') group by a1,a2,b;
|
||||
select a1,a2,b,c from t2 where (a2 >= 'b') and (b = 'a') and (c = 'i121') group by a1,a2,b;
|
||||
select a1,a2,b from t2 where (a1 > 'a') and (a2 > 'a') and (b = 'c') group by a1,a2,b;
|
||||
|
||||
|
||||
--
|
||||
-- DISTINCT queries
|
||||
--
|
||||
|
||||
-- plans
|
||||
explain select distinct a1,a2,b from t1;
|
||||
explain select distinct a1,a2,b from t1 where (a2 >= 'b') and (b = 'a');
|
||||
explain select distinct a1,a2,b,c from t1 where (a2 >= 'b') and (b = 'a') and (c = 'i121');
|
||||
explain select distinct a1,a2,b from t1 where (a1 > 'a') and (a2 > 'a') and (b = 'c');
|
||||
explain select distinct b from t1 where (a2 >= 'b') and (b = 'a');
|
||||
|
||||
explain select distinct a1,a2,b from t2;
|
||||
explain select distinct a1,a2,b from t2 where (a2 >= 'b') and (b = 'a');
|
||||
explain select distinct a1,a2,b,c from t2 where (a2 >= 'b') and (b = 'a') and (c = 'i121');
|
||||
explain select distinct a1,a2,b from t2 where (a1 > 'a') and (a2 > 'a') and (b = 'c');
|
||||
explain select distinct b from t2 where (a2 >= 'b') and (b = 'a');
|
||||
|
||||
-- queries
|
||||
select distinct a1,a2,b from t1;
|
||||
select distinct a1,a2,b from t1 where (a2 >= 'b') and (b = 'a');
|
||||
select distinct a1,a2,b,c from t1 where (a2 >= 'b') and (b = 'a') and (c = 'i121');
|
||||
select distinct a1,a2,b from t1 where (a1 > 'a') and (a2 > 'a') and (b = 'c');
|
||||
select distinct b from t1 where (a2 >= 'b') and (b = 'a');
|
||||
|
||||
select distinct a1,a2,b from t2;
|
||||
select distinct a1,a2,b from t2 where (a2 >= 'b') and (b = 'a');
|
||||
select distinct a1,a2,b,c from t2 where (a2 >= 'b') and (b = 'a') and (c = 'i121');
|
||||
select distinct a1,a2,b from t2 where (a1 > 'a') and (a2 > 'a') and (b = 'c');
|
||||
select distinct b from t2 where (a2 >= 'b') and (b = 'a');
|
||||
|
||||
|
||||
--
|
||||
-- DISTINCT queries with GROUP-BY
|
||||
--
|
||||
|
||||
-- plans
|
||||
explain select distinct a1,a2,b from t1;
|
||||
explain select distinct a1,a2,b from t1 where (a2 >= 'b') and (b = 'a') group by a1,a2,b;
|
||||
explain select distinct a1,a2,b,c from t1 where (a2 >= 'b') and (b = 'a') and (c = 'i121') group by a1,a2,b;
|
||||
explain select distinct a1,a2,b from t1 where (a1 > 'a') and (a2 > 'a') and (b = 'c') group by a1,a2,b;
|
||||
explain select distinct b from t1 where (a2 >= 'b') and (b = 'a') group by a1,a2,b;
|
||||
|
||||
explain select distinct a1,a2,b from t2;
|
||||
explain select distinct a1,a2,b from t2 where (a2 >= 'b') and (b = 'a') group by a1,a2,b;
|
||||
explain select distinct a1,a2,b,c from t2 where (a2 >= 'b') and (b = 'a') and (c = 'i121') group by a1,a2,b;
|
||||
explain select distinct a1,a2,b from t2 where (a1 > 'a') and (a2 > 'a') and (b = 'c') group by a1,a2,b;
|
||||
explain select distinct b from t2 where (a2 >= 'b') and (b = 'a') group by a1,a2,b;
|
||||
|
||||
-- queries
|
||||
select distinct a1,a2,b from t1;
|
||||
select distinct a1,a2,b from t1 where (a2 >= 'b') and (b = 'a') group by a1,a2,b;
|
||||
select distinct a1,a2,b,c from t1 where (a2 >= 'b') and (b = 'a') and (c = 'i121') group by a1,a2,b;
|
||||
select distinct a1,a2,b from t1 where (a1 > 'a') and (a2 > 'a') and (b = 'c') group by a1,a2,b;
|
||||
select distinct b from t1 where (a2 >= 'b') and (b = 'a') group by a1,a2,b;
|
||||
|
||||
select distinct a1,a2,b from t2;
|
||||
select distinct a1,a2,b from t2 where (a2 >= 'b') and (b = 'a') group by a1,a2,b;
|
||||
select distinct a1,a2,b,c from t2 where (a2 >= 'b') and (b = 'a') and (c = 'i121') group by a1,a2,b;
|
||||
select distinct a1,a2,b from t2 where (a1 > 'a') and (a2 > 'a') and (b = 'c') group by a1,a2,b;
|
||||
select distinct b from t2 where (a2 >= 'b') and (b = 'a') group by a1,a2,b;
|
||||
|
||||
|
||||
--
|
||||
-- COUNT (DISTINCT cols) queries
|
||||
--
|
||||
|
||||
explain select count(distinct a1,a2,b) from t1 where (a2 >= 'b') and (b = 'a');
|
||||
explain select count(distinct a1,a2,b,c) from t1 where (a2 >= 'b') and (b = 'a') and (c = 'i121');
|
||||
explain select count(distinct a1,a2,b) from t1 where (a1 > 'a') and (a2 > 'a') and (b = 'c');
|
||||
explain select count(distinct b) from t1 where (a2 >= 'b') and (b = 'a');
|
||||
explain select ord(a1) + count(distinct a1,a2,b) from t1 where (a1 > 'a') and (a2 > 'a');
|
||||
|
||||
select count(distinct a1,a2,b) from t1 where (a2 >= 'b') and (b = 'a');
|
||||
select count(distinct a1,a2,b,c) from t1 where (a2 >= 'b') and (b = 'a') and (c = 'i121');
|
||||
select count(distinct a1,a2,b) from t1 where (a1 > 'a') and (a2 > 'a') and (b = 'c');
|
||||
select count(distinct b) from t1 where (a2 >= 'b') and (b = 'a');
|
||||
select ord(a1) + count(distinct a1,a2,b) from t1 where (a1 > 'a') and (a2 > 'a');
|
||||
|
||||
--
|
||||
-- Queries with expressions in the select clause
|
||||
--
|
||||
|
||||
explain select a1,a2,b, concat(min(c), max(c)) from t1 where a1 < 'd' group by a1,a2,b;
|
||||
explain select concat(a1,min(c)),b from t1 where a1 < 'd' group by a1,a2,b;
|
||||
explain select concat(a1,min(c)),b,max(c) from t1 where a1 < 'd' group by a1,a2,b;
|
||||
explain select concat(a1,a2),b,min(c),max(c) from t1 where a1 < 'd' group by a1,a2,b;
|
||||
explain select concat(ord(min(b)),ord(max(b))),min(b),max(b) from t1 group by a1,a2;
|
||||
|
||||
select a1,a2,b, concat(min(c), max(c)) from t1 where a1 < 'd' group by a1,a2,b;
|
||||
select concat(a1,min(c)),b from t1 where a1 < 'd' group by a1,a2,b;
|
||||
select concat(a1,min(c)),b,max(c) from t1 where a1 < 'd' group by a1,a2,b;
|
||||
select concat(a1,a2),b,min(c),max(c) from t1 where a1 < 'd' group by a1,a2,b;
|
||||
select concat(ord(min(b)),ord(max(b))),min(b),max(b) from t1 group by a1,a2;
|
||||
|
||||
|
||||
--
|
||||
-- Negative examples: queries that should NOT be treated as optimizable by
|
||||
-- QUICK_GROUP_MIN_MAX_SELECT
|
||||
--
|
||||
|
||||
-- select a non-indexed attribute
|
||||
explain select a1,a2,b,d,min(c),max(c) from t1 group by a1,a2,b;
|
||||
|
||||
explain select a1,a2,b,d from t1 group by a1,a2,b;
|
||||
|
||||
-- predicate that references an attribute that is after the MIN/MAX argument
|
||||
-- in the index
|
||||
explain select a1,a2,min(b),max(b) from t1
|
||||
where (a1 = 'b' or a1 = 'd' or a1 = 'a' or a1 = 'c') and (a2 > 'a') and (c > 'a111') group by a1,a2;
|
||||
|
||||
-- predicate that references a non-indexed attribute
|
||||
explain select a1,a2,b,min(c),max(c) from t1
|
||||
where (a1 = 'b' or a1 = 'd' or a1 = 'a' or a1 = 'c') and (a2 > 'a') and (d > 'xy2') group by a1,a2,b;
|
||||
|
||||
explain select a1,a2,b,c from t1
|
||||
where (a1 = 'b' or a1 = 'd' or a1 = 'a' or a1 = 'c') and (a2 > 'a') and (d > 'xy2') group by a1,a2,b,c;
|
||||
|
||||
-- non-equality predicate for a non-group select attribute
|
||||
explain select a1,a2,b,max(c),min(c) from t2 where (a2 = 'a') and (b = 'b') or (b < 'b') group by a1;
|
||||
explain select a1,a2,b from t1 where (a1 = 'b' or a1 = 'd' or a1 = 'a' or a1 = 'c') and (a2 > 'a') and (c > 'a111') group by a1,a2,b;
|
||||
|
||||
-- disjunction for a non-group select attribute
|
||||
explain select a1,a2,b,max(c),min(c) from t2 where (a2 = 'a') and (b = 'b') or (b = 'a') group by a1;
|
||||
|
||||
-- non-range predicate for the MIN/MAX attribute
|
||||
explain select a1,a2,b,min(c),max(c) from t2
|
||||
where (c > 'a000') and (c <= 'd999') and (c like '_8__') group by a1,a2,b;
|
||||
|
||||
-- not all attributes are indexed by one index
|
||||
explain select a1, a2, b, c, min(d), max(d) from t1 group by a1,a2,b,c;
|
||||
|
||||
-- other aggregate functions than MIN/MAX
|
||||
explain select a1,a2,count(a2) from t1 group by a1,a2,b;
|
||||
explain select a1,a2,count(a2) from t1 where (a1 > 'a') group by a1,a2,b;
|
||||
explain select sum(ord(a1)) from t1 where (a1 > 'a') group by a1,a2,b;
|
||||
|
||||
drop table t1;
|
||||
drop table t2;
|
||||
drop table t3;
|
|
@ -1515,8 +1515,9 @@ longlong ha_myisam::get_auto_increment()
|
|||
int error;
|
||||
byte key[MI_MAX_KEY_LENGTH];
|
||||
(void) extra(HA_EXTRA_KEYREAD);
|
||||
key_copy(key,table,table->next_number_index,
|
||||
table->next_number_key_offset);
|
||||
key_copy(key, table->record[0],
|
||||
table->key_info + table->next_number_index,
|
||||
table->next_number_key_offset);
|
||||
error=mi_rkey(file,table->record[1],(int) table->next_number_index,
|
||||
key,table->next_number_key_offset,HA_READ_PREFIX_LAST);
|
||||
if (error)
|
||||
|
|
|
@ -984,7 +984,8 @@ longlong handler::get_auto_increment()
|
|||
else
|
||||
{
|
||||
byte key[MAX_KEY_LENGTH];
|
||||
key_copy(key,table,table->next_number_index,
|
||||
key_copy(key, table->record[0],
|
||||
table->key_info + table->next_number_index,
|
||||
table->next_number_key_offset);
|
||||
error=index_read(table->record[1], key, table->next_number_key_offset,
|
||||
HA_READ_PREFIX_LAST);
|
||||
|
|
40
sql/item.cc
40
sql/item.cc
|
@ -159,6 +159,46 @@ bool Item_ident::remove_dependence_processor(byte * arg)
|
|||
}
|
||||
|
||||
|
||||
/*
|
||||
Store the pointer to this item field into a list if not already there.
|
||||
|
||||
SYNOPSIS
|
||||
Item_field::collect_item_field_processor()
|
||||
arg pointer to a List<Item_field>
|
||||
|
||||
DESCRIPTION
|
||||
The method is used by Item::walk to collect all unique Item_field objects
|
||||
from a tree of Items into a set of items represented as a list.
|
||||
|
||||
IMPLEMENTATION
|
||||
Item_cond::walk() and Item_func::walk() stop the evaluation of the
|
||||
processor function for its arguments once the processor returns
|
||||
true.Therefore in order to force this method being called for all item
|
||||
arguments in a condition the method must return false.
|
||||
|
||||
RETURN
|
||||
false on success (force the evaluation of collect_item_field_processor
|
||||
for the subsequent items.)
|
||||
true o/w (stop evaluation of subsequent items.)
|
||||
*/
|
||||
|
||||
bool Item_field::collect_item_field_processor(byte *arg)
|
||||
{
|
||||
DBUG_ENTER("Item_field::collect_item_field_processor");
|
||||
DBUG_PRINT("info", ("%s", field->field_name ? field->field_name : "noname"));
|
||||
List<Item_field> *item_list= (List<Item_field>*) arg;
|
||||
List_iterator<Item_field> item_list_it(*item_list);
|
||||
Item_field *curr_item;
|
||||
while ((curr_item= item_list_it++))
|
||||
{
|
||||
if (curr_item->eq(this, 1))
|
||||
DBUG_RETURN(false); /* Already in the set. */
|
||||
}
|
||||
item_list->push_back(this);
|
||||
DBUG_RETURN(false);
|
||||
}
|
||||
|
||||
|
||||
bool Item::check_cols(uint c)
|
||||
{
|
||||
if (c != 1)
|
||||
|
|
19
sql/item.h
19
sql/item.h
|
@ -260,6 +260,22 @@ public:
|
|||
|
||||
virtual bool remove_dependence_processor(byte * arg) { return 0; }
|
||||
virtual bool remove_fixed(byte * arg) { fixed= 0; return 0; }
|
||||
/*
|
||||
All collect_* methods are used as arguments to walk() to collect
|
||||
specific types items.
|
||||
TODO:
|
||||
A more generic implementation would add a special class
|
||||
Collect_processor_param that can store arbitrary sets of item kinds
|
||||
(currently specified as enums), along with a list to store items of the
|
||||
specified kinds. This would allow to collect combinations of items of
|
||||
arbitrary kinds without having to add a new collect method each time.
|
||||
There can be one generic collect_processor method that checks the item type
|
||||
and compares it with the item types in Collect_processor_param.
|
||||
*/
|
||||
virtual bool collect_item_field_processor(byte * arg) { return 0; }
|
||||
virtual bool collect_item_sum_min_processor(byte * arg) { return 0; }
|
||||
virtual bool collect_item_sum_max_processor(byte * arg) { return 0; }
|
||||
virtual bool has_non_min_max_sum_processor(byte * arg) { return 0; }
|
||||
|
||||
virtual Item *this_item() { return this; } /* For SPs mostly. */
|
||||
virtual Item *this_const_item() const { return const_cast<Item*>(this); } /* For SPs mostly. */
|
||||
|
@ -493,6 +509,7 @@ public:
|
|||
bool get_time(TIME *ltime);
|
||||
bool is_null() { return field->is_null(); }
|
||||
Item *get_tmp_table_item(THD *thd);
|
||||
bool collect_item_field_processor(byte * arg);
|
||||
void cleanup();
|
||||
inline uint32 max_disp_length() { return field->max_length(); }
|
||||
friend class Item_default_value;
|
||||
|
@ -984,6 +1001,8 @@ public:
|
|||
(*ref)->save_in_field(result_field, no_conversions);
|
||||
}
|
||||
Item *real_item() { return *ref; }
|
||||
bool walk(Item_processor processor, byte *arg)
|
||||
{ return (*ref)->walk(processor, arg); }
|
||||
void print(String *str);
|
||||
void cleanup();
|
||||
};
|
||||
|
|
|
@ -182,6 +182,45 @@ bool Item_sum::walk (Item_processor processor, byte *argument)
|
|||
return (this->*processor)(argument);
|
||||
}
|
||||
|
||||
|
||||
/*
|
||||
Store the pointer to this item into a list if not already there.
|
||||
|
||||
SYNOPSIS
|
||||
Item_sum::collect()
|
||||
item_list pointer to a List<Item_sum> where item_sum objects are collected
|
||||
|
||||
DESCRIPTION
|
||||
The method is used by collect_item_sum_*_processor, called by
|
||||
Item_sum::walk, to collect all unique Item_sum_min and Item_sum_max objects
|
||||
from a tree of Items into a set of items represented as a list.
|
||||
|
||||
IMPLEMENTATION
|
||||
Item_cond::walk() and Item_func::walk() stop the evaluation of the
|
||||
processor function for its arguments once the processor returns
|
||||
true.Therefore in order to force this method being called for all item
|
||||
arguments in a condition the method must return false.
|
||||
|
||||
RETURN
|
||||
FALSE on success (force the evaluation of collect_item_sum_*_processor
|
||||
for the subsequent items.)
|
||||
TRUE o/w (stop evaluation of subsequent items.)
|
||||
*/
|
||||
|
||||
bool Item_sum::collect(List<Item_sum> *item_list)
|
||||
{
|
||||
List_iterator<Item_sum> item_list_it(*item_list);
|
||||
Item_sum *curr_item;
|
||||
while ((curr_item= item_list_it++))
|
||||
{
|
||||
if (curr_item == this)
|
||||
return FALSE; /* Already in the set. */
|
||||
}
|
||||
item_list->push_back(this);
|
||||
return FALSE;
|
||||
}
|
||||
|
||||
|
||||
String *
|
||||
Item_sum_num::val_str(String *str)
|
||||
{
|
||||
|
|
|
@ -27,6 +27,8 @@ class Item_arena;
|
|||
|
||||
class Item_sum :public Item_result_field
|
||||
{
|
||||
private:
|
||||
bool collect(List<Item_sum> *item_list);
|
||||
public:
|
||||
enum Sumfunctype
|
||||
{ COUNT_FUNC, COUNT_DISTINCT_FUNC, SUM_FUNC, SUM_DISTINCT_FUNC, AVG_FUNC,
|
||||
|
@ -98,6 +100,33 @@ public:
|
|||
bool save_args(Item_arena* stmt);
|
||||
|
||||
bool walk (Item_processor processor, byte *argument);
|
||||
|
||||
/* Collect Item_sum_min objects into a list supplied by the caller. */
|
||||
bool collect_item_sum_min_processor(byte *arg)
|
||||
{
|
||||
if (Item_sum::MIN_FUNC == this->sum_func())
|
||||
return collect((List<Item_sum>*) arg);
|
||||
else
|
||||
return FALSE;
|
||||
}
|
||||
|
||||
/* Collect Item_sum_max objects into a list supplied by the caller. */
|
||||
bool collect_item_sum_max_processor(byte *arg)
|
||||
{
|
||||
if (Item_sum::MAX_FUNC == this->sum_func())
|
||||
return collect((List<Item_sum>*) arg);
|
||||
else
|
||||
return FALSE;
|
||||
}
|
||||
|
||||
/* Check if there are any aggregate functions other than MIN and MAX. */
|
||||
bool has_non_min_max_sum_processor(byte * arg)
|
||||
{
|
||||
Sumfunctype sum_type= this->sum_func();
|
||||
if ((sum_type != Item_sum::MIN_FUNC) && (sum_type != Item_sum::MAX_FUNC))
|
||||
return TRUE;
|
||||
return FALSE;
|
||||
}
|
||||
};
|
||||
|
||||
|
||||
|
|
113
sql/key.cc
113
sql/key.cc
|
@ -66,94 +66,121 @@ int find_ref_key(TABLE *table,Field *field, uint *key_length)
|
|||
}
|
||||
|
||||
|
||||
/* Copy a key from record to some buffer */
|
||||
/* if length == 0 then copy whole key */
|
||||
/*
|
||||
Copy part of a record that forms a key or key prefix to a buffer.
|
||||
|
||||
void key_copy(byte *key,TABLE *table,uint idx,uint key_length)
|
||||
SYNOPSIS
|
||||
key_copy()
|
||||
to_key buffer that will be used as a key
|
||||
from_record full record to be copied from
|
||||
key_info descriptor of the index
|
||||
key_length specifies length of all keyparts that will be copied
|
||||
|
||||
DESCRIPTION
|
||||
The function takes a complete table record (as e.g. retrieved by
|
||||
handler::index_read()), and a description of an index on the same table,
|
||||
and extracts the first key_length bytes of the record which are part of a
|
||||
key into to_key. If length == 0 then copy all bytes from the record that
|
||||
form a key.
|
||||
|
||||
RETURN
|
||||
None
|
||||
*/
|
||||
|
||||
void key_copy(byte *to_key, byte *from_record, KEY *key_info, uint key_length)
|
||||
{
|
||||
uint length;
|
||||
KEY *key_info=table->key_info+idx;
|
||||
KEY_PART_INFO *key_part;
|
||||
|
||||
if (key_length == 0)
|
||||
key_length=key_info->key_length;
|
||||
for (key_part=key_info->key_part;
|
||||
(int) key_length > 0 ;
|
||||
key_part++)
|
||||
key_length= key_info->key_length;
|
||||
for (key_part= key_info->key_part; (int) key_length > 0; key_part++)
|
||||
{
|
||||
if (key_part->null_bit)
|
||||
{
|
||||
*key++= test(table->record[0][key_part->null_offset] &
|
||||
*to_key++= test(from_record[key_part->null_offset] &
|
||||
key_part->null_bit);
|
||||
key_length--;
|
||||
}
|
||||
if (key_part->key_part_flag & HA_BLOB_PART)
|
||||
{
|
||||
char *pos;
|
||||
ulong blob_length=((Field_blob*) key_part->field)->get_length();
|
||||
key_length-=2;
|
||||
ulong blob_length= ((Field_blob*) key_part->field)->get_length();
|
||||
key_length-= 2;
|
||||
((Field_blob*) key_part->field)->get_ptr(&pos);
|
||||
length=min(key_length,key_part->length);
|
||||
set_if_smaller(blob_length,length);
|
||||
int2store(key,(uint) blob_length);
|
||||
key+=2; // Skip length info
|
||||
memcpy(key,pos,blob_length);
|
||||
length=min(key_length, key_part->length);
|
||||
set_if_smaller(blob_length, length);
|
||||
int2store(to_key, (uint) blob_length);
|
||||
to_key+= 2; // Skip length info
|
||||
memcpy(to_key, pos, blob_length);
|
||||
}
|
||||
else
|
||||
{
|
||||
length=min(key_length,key_part->length);
|
||||
memcpy(key,table->record[0]+key_part->offset,(size_t) length);
|
||||
length= min(key_length, key_part->length);
|
||||
memcpy(to_key, from_record + key_part->offset, (size_t) length);
|
||||
}
|
||||
key+=length;
|
||||
key_length-=length;
|
||||
to_key+= length;
|
||||
key_length-= length;
|
||||
}
|
||||
} /* key_copy */
|
||||
}
|
||||
|
||||
|
||||
/* restore a key from some buffer to record */
|
||||
/*
|
||||
Restore a key from some buffer to record.
|
||||
|
||||
void key_restore(TABLE *table,byte *key,uint idx,uint key_length)
|
||||
SYNOPSIS
|
||||
key_restore()
|
||||
to_record record buffer where the key will be restored to
|
||||
from_key buffer that contains a key
|
||||
key_info descriptor of the index
|
||||
key_length specifies length of all keyparts that will be restored
|
||||
|
||||
DESCRIPTION
|
||||
This function converts a key into record format. It can be used in cases
|
||||
when we want to return a key as a result row.
|
||||
|
||||
RETURN
|
||||
None
|
||||
*/
|
||||
|
||||
void key_restore(byte *to_record, byte *from_key, KEY *key_info,
|
||||
uint key_length)
|
||||
{
|
||||
uint length;
|
||||
KEY *key_info=table->key_info+idx;
|
||||
KEY_PART_INFO *key_part;
|
||||
|
||||
if (key_length == 0)
|
||||
{
|
||||
if (idx == (uint) -1)
|
||||
return;
|
||||
key_length=key_info->key_length;
|
||||
key_length= key_info->key_length;
|
||||
}
|
||||
for (key_part=key_info->key_part;
|
||||
(int) key_length > 0 ;
|
||||
key_part++)
|
||||
for (key_part= key_info->key_part ; (int) key_length > 0 ; key_part++)
|
||||
{
|
||||
if (key_part->null_bit)
|
||||
{
|
||||
if (*key++)
|
||||
table->record[0][key_part->null_offset]|= key_part->null_bit;
|
||||
if (*from_key++)
|
||||
to_record[key_part->null_offset]|= key_part->null_bit;
|
||||
else
|
||||
table->record[0][key_part->null_offset]&= ~key_part->null_bit;
|
||||
to_record[key_part->null_offset]&= ~key_part->null_bit;
|
||||
key_length--;
|
||||
}
|
||||
if (key_part->key_part_flag & HA_BLOB_PART)
|
||||
{
|
||||
uint blob_length=uint2korr(key);
|
||||
key+=2;
|
||||
key_length-=2;
|
||||
uint blob_length= uint2korr(from_key);
|
||||
from_key+= 2;
|
||||
key_length-= 2;
|
||||
((Field_blob*) key_part->field)->set_ptr((ulong) blob_length,
|
||||
(char*) key);
|
||||
length=key_part->length;
|
||||
(char*) from_key);
|
||||
length= key_part->length;
|
||||
}
|
||||
else
|
||||
{
|
||||
length=min(key_length,key_part->length);
|
||||
memcpy(table->record[0]+key_part->offset,key,(size_t) length);
|
||||
length= min(key_length, key_part->length);
|
||||
memcpy(to_record + key_part->offset, from_key, (size_t) length);
|
||||
}
|
||||
key+=length;
|
||||
key_length-=length;
|
||||
from_key+= length;
|
||||
key_length-= length;
|
||||
}
|
||||
} /* key_restore */
|
||||
}
|
||||
|
||||
|
||||
/*
|
||||
|
|
|
@ -733,7 +733,8 @@ bool add_proc_to_list(THD *thd, Item *item);
|
|||
TABLE *unlink_open_table(THD *thd,TABLE *list,TABLE *find);
|
||||
|
||||
SQL_SELECT *make_select(TABLE *head, table_map const_tables,
|
||||
table_map read_tables, COND *conds, int *error);
|
||||
table_map read_tables, COND *conds, int *error,
|
||||
bool allow_null_cond= false);
|
||||
enum find_item_error_report_type {REPORT_ALL_ERRORS, REPORT_EXCEPT_NOT_FOUND,
|
||||
IGNORE_ERRORS};
|
||||
extern const Item **not_found_item;
|
||||
|
@ -814,8 +815,9 @@ void print_plan(JOIN* join, double read_time, double record_count,
|
|||
void mysql_print_status(THD *thd);
|
||||
/* key.cc */
|
||||
int find_ref_key(TABLE *form,Field *field, uint *offset);
|
||||
void key_copy(byte *key,TABLE *form,uint index,uint key_length);
|
||||
void key_restore(TABLE *form,byte *key,uint index,uint key_length);
|
||||
void key_copy(byte *to_key, byte *from_record, KEY *key_info, uint key_length);
|
||||
void key_restore(byte *to_record, byte *from_key, KEY *key_info,
|
||||
uint key_length);
|
||||
bool key_cmp_if_same(TABLE *form,const byte *key,uint index,uint key_length);
|
||||
void key_unpack(String *to,TABLE *form,uint index);
|
||||
bool check_if_key_used(TABLE *table, uint idx, List<Item> &fields);
|
||||
|
|
2255
sql/opt_range.cc
2255
sql/opt_range.cc
File diff suppressed because it is too large
Load diff
106
sql/opt_range.h
106
sql/opt_range.h
|
@ -146,7 +146,8 @@ public:
|
|||
QS_TYPE_RANGE_DESC = 2,
|
||||
QS_TYPE_FULLTEXT = 3,
|
||||
QS_TYPE_ROR_INTERSECT = 4,
|
||||
QS_TYPE_ROR_UNION = 5
|
||||
QS_TYPE_ROR_UNION = 5,
|
||||
QS_TYPE_GROUP_MIN_MAX = 6
|
||||
};
|
||||
|
||||
/* Get type of this quick select - one of the QS_TYPE_* values */
|
||||
|
@ -278,14 +279,12 @@ public:
|
|||
int init();
|
||||
int get_next();
|
||||
void range_end();
|
||||
|
||||
int get_next_prefix(uint prefix_length, byte *cur_prefix);
|
||||
bool reverse_sorted() { return 0; }
|
||||
bool unique_key_range();
|
||||
int init_ror_merged_scan(bool reuse_handler);
|
||||
void save_last_pos()
|
||||
{
|
||||
file->position(record);
|
||||
};
|
||||
{ file->position(record); }
|
||||
int get_type() { return QS_TYPE_RANGE; }
|
||||
void add_keys_and_lengths(String *key_names, String *used_lengths);
|
||||
void add_info_string(String *str);
|
||||
|
@ -518,6 +517,103 @@ private:
|
|||
};
|
||||
|
||||
|
||||
/*
|
||||
Index scan for GROUP-BY queries with MIN/MAX aggregate functions.
|
||||
|
||||
This class provides a specialized index access method for GROUP-BY queries
|
||||
of the forms:
|
||||
|
||||
SELECT A_1,...,A_k, [B_1,...,B_m], [MIN(C)], [MAX(C)]
|
||||
FROM T
|
||||
WHERE [RNG(A_1,...,A_p ; where p <= k)]
|
||||
[AND EQ(B_1,...,B_m)]
|
||||
[AND PC(C)]
|
||||
[AND PA(A_i1,...,A_iq)]
|
||||
GROUP BY A_1,...,A_k;
|
||||
|
||||
or
|
||||
|
||||
SELECT DISTINCT A_i1,...,A_ik
|
||||
FROM T
|
||||
WHERE [RNG(A_1,...,A_p ; where p <= k)]
|
||||
[AND PA(A_i1,...,A_iq)];
|
||||
|
||||
where all selected fields are parts of the same index.
|
||||
The class of queries that can be processed by this quick select is fully
|
||||
specified in the description of get_best_trp_group_min_max() in opt_range.cc.
|
||||
|
||||
The get_next() method directly produces result tuples, thus obviating the
|
||||
need to call end_send_group() because all grouping is already done inside
|
||||
get_next().
|
||||
|
||||
Since one of the requirements is that all select fields are part of the same
|
||||
index, this class produces only index keys, and not complete records.
|
||||
*/
|
||||
|
||||
class QUICK_GROUP_MIN_MAX_SELECT : public QUICK_SELECT_I
|
||||
{
|
||||
private:
|
||||
handler *file; /* The handler used to get data. */
|
||||
JOIN *join; /* Descriptor of the current query */
|
||||
KEY *index_info; /* The index chosen for data access */
|
||||
byte *record; /* Buffer where the next record is returned. */
|
||||
byte *tmp_record; /* Temporary storage for next_min(), next_max(). */
|
||||
byte *group_prefix; /* Key prefix consisting of the GROUP fields. */
|
||||
uint group_prefix_len; /* Length of the group prefix. */
|
||||
byte *last_prefix; /* Prefix of the last group for detecting EOF. */
|
||||
bool have_min; /* Specify whether we are computing */
|
||||
bool have_max; /* a MIN, a MAX, or both. */
|
||||
bool seen_first_key; /* Denotes whether the first key was retrieved.*/
|
||||
KEY_PART_INFO *min_max_arg_part; /* The keypart of the only argument field */
|
||||
/* of all MIN/MAX functions. */
|
||||
uint min_max_arg_len; /* The length of the MIN/MAX argument field */
|
||||
byte *key_infix; /* Infix of constants from equality predicates. */
|
||||
uint key_infix_len;
|
||||
DYNAMIC_ARRAY min_max_ranges; /* Array of range ptrs for the MIN/MAX field. */
|
||||
uint real_prefix_len; /* Length of key prefix extended with key_infix. */
|
||||
List<Item_sum> *min_functions;
|
||||
List<Item_sum> *max_functions;
|
||||
List_iterator<Item_sum> *min_functions_it;
|
||||
List_iterator<Item_sum> *max_functions_it;
|
||||
public:
|
||||
/*
|
||||
The following two members are public to allow easy access from
|
||||
TRP_GROUP_MIN_MAX::make_quick()
|
||||
*/
|
||||
MEM_ROOT alloc; /* Memory pool for this and quick_prefix_select data. */
|
||||
QUICK_RANGE_SELECT *quick_prefix_select;/* For retrieval of group prefixes. */
|
||||
private:
|
||||
int next_prefix();
|
||||
int next_min_in_range();
|
||||
int next_max_in_range();
|
||||
int next_min();
|
||||
int next_max();
|
||||
void update_min_result();
|
||||
void update_max_result();
|
||||
public:
|
||||
QUICK_GROUP_MIN_MAX_SELECT(TABLE *table, JOIN *join, bool have_min,
|
||||
bool have_max, KEY_PART_INFO *min_max_arg_part,
|
||||
uint group_prefix_len, uint used_key_parts,
|
||||
KEY *index_info, uint use_index, double read_cost,
|
||||
ha_rows records, uint key_infix_len,
|
||||
byte *key_infix, MEM_ROOT *parent_alloc);
|
||||
~QUICK_GROUP_MIN_MAX_SELECT();
|
||||
bool add_range(SEL_ARG *sel_range);
|
||||
void update_key_stat();
|
||||
bool alloc_buffers();
|
||||
int init();
|
||||
int reset();
|
||||
int get_next();
|
||||
bool reverse_sorted() { return false; }
|
||||
bool unique_key_range() { return false; }
|
||||
int get_type() { return QS_TYPE_GROUP_MIN_MAX; }
|
||||
void add_keys_and_lengths(String *key_names, String *used_lengths);
|
||||
#ifndef DBUG_OFF
|
||||
void dbug_dump(int indent, bool verbose);
|
||||
#endif
|
||||
};
|
||||
|
||||
|
||||
class QUICK_SELECT_DESC: public QUICK_RANGE_SELECT
|
||||
{
|
||||
public:
|
||||
|
|
|
@ -336,7 +336,7 @@ int opt_sum_query(TABLE_LIST *tables, List<Item> &all_fields,COND *conds)
|
|||
1 Otherwise
|
||||
*/
|
||||
|
||||
static bool simple_pred(Item_func *func_item, Item **args, bool *inv_order)
|
||||
bool simple_pred(Item_func *func_item, Item **args, bool *inv_order)
|
||||
{
|
||||
Item *item;
|
||||
*inv_order= 0;
|
||||
|
|
|
@ -1884,7 +1884,7 @@ GRANT_TABLE::GRANT_TABLE(TABLE *form, TABLE *col_privs)
|
|||
col_privs->field[1]->pack_length()+
|
||||
col_privs->field[2]->pack_length()+
|
||||
col_privs->field[3]->pack_length());
|
||||
key_copy(key,col_privs,0,key_len);
|
||||
key_copy(key,col_privs->record[0],col_privs->key_info,key_len);
|
||||
col_privs->field[4]->store("",0, &my_charset_latin1);
|
||||
col_privs->file->ha_index_init(0);
|
||||
if (col_privs->file->index_read(col_privs->record[0],
|
||||
|
@ -1996,7 +1996,7 @@ static int replace_column_table(GRANT_TABLE *g_t,
|
|||
table->field[3]->store(table_name,(uint) strlen(table_name), &my_charset_latin1);
|
||||
key_length=(table->field[0]->pack_length()+ table->field[1]->pack_length()+
|
||||
table->field[2]->pack_length()+ table->field[3]->pack_length());
|
||||
key_copy(key,table,0,key_length);
|
||||
key_copy(key,table->record[0],table->key_info,key_length);
|
||||
|
||||
rights &= COL_ACLS; // Only ACL for columns
|
||||
|
||||
|
@ -2009,7 +2009,7 @@ static int replace_column_table(GRANT_TABLE *g_t,
|
|||
{
|
||||
ulong privileges = xx->rights;
|
||||
bool old_row_exists=0;
|
||||
key_restore(table,key,0,key_length);
|
||||
key_restore(table->record[0],key,table->key_info,key_length);
|
||||
table->field[4]->store(xx->column.ptr(),xx->column.length(),
|
||||
&my_charset_latin1);
|
||||
|
||||
|
@ -2025,7 +2025,7 @@ static int replace_column_table(GRANT_TABLE *g_t,
|
|||
}
|
||||
old_row_exists = 0;
|
||||
restore_record(table,default_values); // Get empty record
|
||||
key_restore(table,key,0,key_length);
|
||||
key_restore(table->record[0],key,table->key_info,key_length);
|
||||
table->field[4]->store(xx->column.ptr(),xx->column.length(),
|
||||
&my_charset_latin1);
|
||||
}
|
||||
|
|
|
@ -333,7 +333,7 @@ int mysql_ha_read(THD *thd, TABLE_LIST *tables,
|
|||
send_error(thd,ER_OUTOFMEMORY);
|
||||
goto err;
|
||||
}
|
||||
key_copy(key, table, keyno, key_len);
|
||||
key_copy(key, table->record[0], table->key_info + keyno, key_len);
|
||||
err=table->file->index_read(table->record[0],
|
||||
key,key_len,ha_rkey_mode);
|
||||
mode=rkey_to_rnext[(int)ha_rkey_mode];
|
||||
|
|
|
@ -635,7 +635,7 @@ int write_record(TABLE *table,COPY_INFO *info)
|
|||
goto err;
|
||||
}
|
||||
}
|
||||
key_copy((byte*) key,table,key_nr,0);
|
||||
key_copy((byte*) key,table->record[0],table->key_info+key_nr,0);
|
||||
if ((error=(table->file->index_read_idx(table->record[1],key_nr,
|
||||
(byte*) key,
|
||||
table->key_info[key_nr].
|
||||
|
|
|
@ -188,6 +188,7 @@ static bool update_sum_func(Item_sum **func);
|
|||
static void select_describe(JOIN *join, bool need_tmp_table,bool need_order,
|
||||
bool distinct, const char *message=NullS);
|
||||
static Item *remove_additional_cond(Item* conds);
|
||||
static void add_group_and_distinct_keys(JOIN *join, JOIN_TAB *join_tab);
|
||||
|
||||
|
||||
/*
|
||||
|
@ -635,7 +636,7 @@ JOIN::optimize()
|
|||
conds=new Item_int((longlong) 1,1); // Always true
|
||||
}
|
||||
select=make_select(*table, const_table_map,
|
||||
const_table_map, conds, &error);
|
||||
const_table_map, conds, &error, true);
|
||||
if (error)
|
||||
{ /* purecov: inspected */
|
||||
error= -1; /* purecov: inspected */
|
||||
|
@ -2304,6 +2305,12 @@ make_join_statistics(JOIN *join,TABLE_LIST *tables,COND *conds,
|
|||
if (s->worst_seeks < 2.0) // Fix for small tables
|
||||
s->worst_seeks=2.0;
|
||||
|
||||
/*
|
||||
Add to stat->const_keys those indexes for which all group fields or
|
||||
all select distinct fields participate in one index.
|
||||
*/
|
||||
add_group_and_distinct_keys(join, s);
|
||||
|
||||
if (!s->const_keys.is_clear_all() &&
|
||||
!s->table->pos_in_table_list->embedding)
|
||||
{
|
||||
|
@ -2312,7 +2319,9 @@ make_join_statistics(JOIN *join,TABLE_LIST *tables,COND *conds,
|
|||
select= make_select(s->table, found_const_table_map,
|
||||
found_const_table_map,
|
||||
s->on_expr ? s->on_expr : conds,
|
||||
&error);
|
||||
&error, true);
|
||||
if (!select)
|
||||
DBUG_RETURN(1);
|
||||
records= get_quick_record_count(join->thd, select, s->table,
|
||||
&s->const_keys, join->row_limit);
|
||||
s->quick=select->quick;
|
||||
|
@ -2347,13 +2356,13 @@ make_join_statistics(JOIN *join,TABLE_LIST *tables,COND *conds,
|
|||
}
|
||||
}
|
||||
|
||||
/* Find best combination and return it */
|
||||
join->join_tab=stat;
|
||||
join->map2table=stat_ref;
|
||||
join->table= join->all_tables=table_vector;
|
||||
join->const_tables=const_count;
|
||||
join->found_const_table_map=found_const_table_map;
|
||||
|
||||
/* Find an optimal join order of the non-constant tables. */
|
||||
if (join->const_tables != join->tables)
|
||||
{
|
||||
optimize_keyuse(join, keyuse_array);
|
||||
|
@ -2365,6 +2374,7 @@ make_join_statistics(JOIN *join,TABLE_LIST *tables,COND *conds,
|
|||
sizeof(POSITION)*join->const_tables);
|
||||
join->best_read=1.0;
|
||||
}
|
||||
/* Generate an execution plan from the found optimal join order. */
|
||||
DBUG_RETURN(join->thd->killed || get_best_combination(join));
|
||||
}
|
||||
|
||||
|
@ -2561,6 +2571,10 @@ add_key_field(KEY_FIELD **key_fields,uint and_level, COND *cond,
|
|||
|
||||
bool is_const=1;
|
||||
for (uint i=0; i<num_values; i++)
|
||||
/*
|
||||
TODO: this looks like a bug, should be
|
||||
is_const&= (value[i])->const_item();
|
||||
*/
|
||||
is_const&= (*value)->const_item();
|
||||
if (is_const)
|
||||
stat[0].const_keys.merge(possible_keys);
|
||||
|
@ -2997,6 +3011,68 @@ static void optimize_keyuse(JOIN *join, DYNAMIC_ARRAY *keyuse_array)
|
|||
}
|
||||
|
||||
|
||||
/*
|
||||
Discover the indexes that can be used for GROUP BY or DISTINCT queries.
|
||||
|
||||
SYNOPSIS
|
||||
add_group_and_distinct_keys()
|
||||
join
|
||||
join_tab
|
||||
|
||||
DESCRIPTION
|
||||
If the query has a GROUP BY clause, find all indexes that contain all
|
||||
GROUP BY fields, and add those indexes to join->const_keys.
|
||||
If the query has a DISTINCT clause, find all indexes that contain all
|
||||
SELECT fields, and add those indexes to join->const_keys.
|
||||
This allows later on such queries to be processed by a
|
||||
QUICK_GROUP_MIN_MAX_SELECT.
|
||||
|
||||
RETURN
|
||||
None
|
||||
*/
|
||||
|
||||
static void
|
||||
add_group_and_distinct_keys(JOIN *join, JOIN_TAB *join_tab)
|
||||
{
|
||||
List<Item_field> indexed_fields;
|
||||
List_iterator<Item_field> indexed_fields_it(indexed_fields);
|
||||
ORDER *cur_group;
|
||||
Item_field *cur_item;
|
||||
key_map possible_keys(0);
|
||||
|
||||
if (join->group_list)
|
||||
{ /* Collect all query fields referenced in the GROUP clause. */
|
||||
for (cur_group= join->group_list; cur_group; cur_group= cur_group->next)
|
||||
(*cur_group->item)->walk(&Item::collect_item_field_processor,
|
||||
(byte*) &indexed_fields);
|
||||
}
|
||||
else if (join->select_distinct)
|
||||
{ /* Collect all query fields referenced in the SELECT clause. */
|
||||
List<Item> &select_items= join->fields_list;
|
||||
List_iterator<Item> select_items_it(select_items);
|
||||
Item *item;
|
||||
while ((item= select_items_it++))
|
||||
item->walk(&Item::collect_item_field_processor, (byte*) &indexed_fields);
|
||||
}
|
||||
else
|
||||
return;
|
||||
|
||||
if (indexed_fields.elements == 0)
|
||||
return;
|
||||
|
||||
/* Intersect the keys of all group fields. */
|
||||
cur_item= indexed_fields_it++;
|
||||
possible_keys.merge(cur_item->field->part_of_key);
|
||||
while ((cur_item= indexed_fields_it++))
|
||||
{
|
||||
possible_keys.intersect(cur_item->field->part_of_key);
|
||||
}
|
||||
|
||||
if (!possible_keys.is_clear_all())
|
||||
join_tab->const_keys.merge(possible_keys);
|
||||
}
|
||||
|
||||
|
||||
/*****************************************************************************
|
||||
Go through all combinations of not marked tables and find the one
|
||||
which uses least records
|
||||
|
@ -4883,20 +4959,23 @@ make_join_select(JOIN *join,SQL_SELECT *select,COND *cond)
|
|||
if (select)
|
||||
{
|
||||
table_map used_tables;
|
||||
if (join->tables > 1)
|
||||
cond->update_used_tables(); // Tablenr may have changed
|
||||
if (join->const_tables == join->tables &&
|
||||
join->thd->lex->current_select->master_unit() ==
|
||||
&join->thd->lex->unit) // not upper level SELECT
|
||||
join->const_table_map|=RAND_TABLE_BIT;
|
||||
{ // Check const tables
|
||||
COND *const_cond=
|
||||
make_cond_for_table(cond,join->const_table_map,(table_map) 0);
|
||||
DBUG_EXECUTE("where",print_where(const_cond,"constants"););
|
||||
if (const_cond && !const_cond->val_int())
|
||||
{
|
||||
DBUG_PRINT("info",("Found impossible WHERE condition"));
|
||||
DBUG_RETURN(1); // Impossible const condition
|
||||
if (cond) /* Because of QUICK_GROUP_MIN_MAX_SELECT */
|
||||
{ /* there may be a select without a cond. */
|
||||
if (join->tables > 1)
|
||||
cond->update_used_tables(); // Tablenr may have changed
|
||||
if (join->const_tables == join->tables &&
|
||||
join->thd->lex->current_select->master_unit() ==
|
||||
&join->thd->lex->unit) // not upper level SELECT
|
||||
join->const_table_map|=RAND_TABLE_BIT;
|
||||
{ // Check const tables
|
||||
COND *const_cond=
|
||||
make_cond_for_table(cond,join->const_table_map,(table_map) 0);
|
||||
DBUG_EXECUTE("where",print_where(const_cond,"constants"););
|
||||
if (const_cond && !const_cond->val_int())
|
||||
{
|
||||
DBUG_PRINT("info",("Found impossible WHERE condition"));
|
||||
DBUG_RETURN(1); // Impossible const condition
|
||||
}
|
||||
}
|
||||
}
|
||||
used_tables=((select->const_tables=join->const_table_map) |
|
||||
|
@ -4928,8 +5007,10 @@ make_join_select(JOIN *join,SQL_SELECT *select,COND *cond)
|
|||
join->best_positions[i].records_read= rows2double(tab->quick->records);
|
||||
}
|
||||
|
||||
COND *tmp=make_cond_for_table(cond,used_tables,current_map);
|
||||
if (!tmp && tab->quick)
|
||||
COND *tmp= NULL;
|
||||
if (cond)
|
||||
tmp= make_cond_for_table(cond,used_tables,current_map);
|
||||
if (cond && !tmp && tab->quick)
|
||||
{ // Outer join
|
||||
/*
|
||||
Hack to handle the case where we only refer to a table
|
||||
|
@ -4937,9 +5018,10 @@ make_join_select(JOIN *join,SQL_SELECT *select,COND *cond)
|
|||
*/
|
||||
tmp=new Item_int((longlong) 1,1); // Always true
|
||||
}
|
||||
if (tmp)
|
||||
if (tmp || !cond)
|
||||
{
|
||||
DBUG_EXECUTE("where",print_where(tmp,tab->table->table_name););
|
||||
if (tmp)
|
||||
DBUG_EXECUTE("where",print_where(tmp,tab->table->table_name););
|
||||
SQL_SELECT *sel=tab->select=(SQL_SELECT*)
|
||||
join->thd->memdup((gptr) select, sizeof(SQL_SELECT));
|
||||
if (!sel)
|
||||
|
@ -4949,10 +5031,18 @@ make_join_select(JOIN *join,SQL_SELECT *select,COND *cond)
|
|||
add a match guard to the pushed down predicate.
|
||||
The guard will turn the predicate on only after
|
||||
the first match for outer tables is encountered.
|
||||
*/
|
||||
if (!(tmp= add_found_match_trig_cond(first_inner_tab, tmp, 0)))
|
||||
DBUG_RETURN(1);
|
||||
tab->select_cond=sel->cond=tmp;
|
||||
*/
|
||||
if (cond)
|
||||
{/*
|
||||
Because of QUICK_GROUP_MIN_MAX_SELECT there may be a select without
|
||||
a cond, so neutralize the hack above.
|
||||
*/
|
||||
if (!(tmp= add_found_match_trig_cond(first_inner_tab, tmp, 0)))
|
||||
DBUG_RETURN(1);
|
||||
tab->select_cond=sel->cond=tmp;
|
||||
}
|
||||
else
|
||||
tab->select_cond= sel->cond= NULL;
|
||||
|
||||
sel->head=tab->table;
|
||||
if (tab->quick)
|
||||
|
@ -4992,7 +5082,8 @@ make_join_select(JOIN *join,SQL_SELECT *select,COND *cond)
|
|||
the index if we are using limit and this is the first table
|
||||
*/
|
||||
|
||||
if ((!tab->keys.is_subset(tab->const_keys) && i > 0) ||
|
||||
if (cond &&
|
||||
(!tab->keys.is_subset(tab->const_keys) && i > 0) ||
|
||||
(!tab->const_keys.is_clear_all() && i == join->const_tables &&
|
||||
join->unit->select_limit_cnt <
|
||||
join->best_positions[i].records_read &&
|
||||
|
@ -5050,7 +5141,8 @@ make_join_select(JOIN *join,SQL_SELECT *select,COND *cond)
|
|||
}
|
||||
if (i != join->const_tables && tab->use_quick != 2)
|
||||
{ /* Read with cache */
|
||||
if ((tmp=make_cond_for_table(cond,
|
||||
if (cond &&
|
||||
(tmp=make_cond_for_table(cond,
|
||||
join->const_table_map |
|
||||
current_map,
|
||||
current_map)))
|
||||
|
@ -7444,11 +7536,18 @@ do_select(JOIN *join,List<Item> *fields,TABLE *table,Procedure *procedure)
|
|||
}
|
||||
else
|
||||
{
|
||||
if (join->sort_and_group || (join->procedure &&
|
||||
join->procedure->flags & PROC_GROUP))
|
||||
end_select=end_send_group;
|
||||
/* Test if data is accessed via QUICK_GROUP_MIN_MAX_SELECT. */
|
||||
bool is_using_quick_group_min_max_select=
|
||||
(join->join_tab->select && join->join_tab->select->quick &&
|
||||
(join->join_tab->select->quick->get_type() ==
|
||||
QUICK_SELECT_I::QS_TYPE_GROUP_MIN_MAX));
|
||||
|
||||
if ((join->sort_and_group ||
|
||||
(join->procedure && join->procedure->flags & PROC_GROUP)) &&
|
||||
!is_using_quick_group_min_max_select)
|
||||
end_select= end_send_group;
|
||||
else
|
||||
end_select=end_send;
|
||||
end_select= end_send;
|
||||
}
|
||||
join->join_tab[join->tables-1].next_select=end_select;
|
||||
|
||||
|
@ -9225,7 +9324,8 @@ test_if_skip_sort_order(JOIN_TAB *tab,ORDER *order,ha_rows select_limit,
|
|||
& HA_READ_PREV) ||
|
||||
quick_type == QUICK_SELECT_I::QS_TYPE_INDEX_MERGE ||
|
||||
quick_type == QUICK_SELECT_I::QS_TYPE_ROR_INTERSECT ||
|
||||
quick_type == QUICK_SELECT_I::QS_TYPE_ROR_UNION)
|
||||
quick_type == QUICK_SELECT_I::QS_TYPE_ROR_UNION ||
|
||||
quick_type == QUICK_SELECT_I::QS_TYPE_GROUP_MIN_MAX)
|
||||
DBUG_RETURN(0); // Use filesort
|
||||
|
||||
/* ORDER BY range_key DESC */
|
||||
|
@ -11455,11 +11555,16 @@ static void select_describe(JOIN *join, bool need_tmp_table, bool need_order,
|
|||
extra.append(tab->keys.print(buf));
|
||||
extra.append(')');
|
||||
}
|
||||
else
|
||||
else if (tab->select->cond)
|
||||
extra.append("; Using where");
|
||||
}
|
||||
if (key_read)
|
||||
extra.append("; Using index");
|
||||
{
|
||||
if (quick_type == QUICK_SELECT_I::QS_TYPE_GROUP_MIN_MAX)
|
||||
extra.append("; Using index for group-by");
|
||||
else
|
||||
extra.append("; Using index");
|
||||
}
|
||||
if (table->reginfo.not_exists_optimize)
|
||||
extra.append("; Not exists");
|
||||
if (need_tmp_table)
|
||||
|
|
|
@ -399,6 +399,7 @@ bool create_myisam_from_heap(THD *thd, TABLE *table, TMP_TABLE_PARAM *param,
|
|||
uint find_shortest_key(TABLE *table, const key_map *usable_keys);
|
||||
|
||||
/* functions from opt_sum.cc */
|
||||
bool simple_pred(Item_func *func_item, Item **args, bool *inv_order);
|
||||
int opt_sum_query(TABLE_LIST *tables, List<Item> &all_fields,COND *conds);
|
||||
|
||||
/* from sql_delete.cc, used by opt_range.cc */
|
||||
|
|
Loading…
Add table
Reference in a new issue