mirror of
https://github.com/MariaDB/server.git
synced 2025-01-17 20:42:30 +01:00
Fixed bug #25407.
The bug could cause choosing a sub-optimal execution plan for a single-table query if a unique index with many null keys were defined for the table. It happened because the code of the check_quick_keys function made an assumption that any key may occur in an unique index only once. Yet this is not true for keys with nulls that may have multiple occurrences in the index.
This commit is contained in:
parent
8760182170
commit
710136217b
4 changed files with 173 additions and 3 deletions
|
@ -30,7 +30,7 @@ id select_type table type possible_keys key key_len ref rows Extra
|
|||
1 SIMPLE t1 ref a,b a 5 const 3 Using where; Using index
|
||||
explain select * from t1 where a is null and b=9 or a is null and b=7 limit 3;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref a,b a 5 const 2 Using where; Using index
|
||||
1 SIMPLE t1 range a,b a 9 NULL 3 Using where; Using index
|
||||
explain select * from t1 where a > 1 and a < 3 limit 1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 range a a 5 NULL 1 Using where; Using index
|
||||
|
@ -258,7 +258,7 @@ INSERT INTO t1 VALUES (1,NULL),(2,NULL),(3,1),(4,2),(5,NULL),(6,NULL),(7,3),(8,4
|
|||
INSERT INTO t2 VALUES (1,NULL),(2,NULL),(3,1),(4,2),(5,NULL),(6,NULL),(7,3),(8,4),(9,NULL),(10,NULL);
|
||||
explain select id from t1 where uniq_id is null;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref idx1 idx1 5 const 1 Using where
|
||||
1 SIMPLE t1 ref idx1 idx1 5 const 5 Using where
|
||||
explain select id from t1 where uniq_id =1;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 const idx1 idx1 5 const 1
|
||||
|
|
|
@ -3642,3 +3642,89 @@ INSERT into t1 values (1), (2), (3);
|
|||
SELECT * FROM t1 LIMIT 2, -1;
|
||||
ERROR 42000: You have an error in your SQL syntax; check the manual that corresponds to your MySQL server version for the right syntax to use near '-1' at line 1
|
||||
DROP TABLE t1;
|
||||
CREATE TABLE t1 (
|
||||
ID_with_null int NULL,
|
||||
ID_better int NOT NULL,
|
||||
INDEX idx1 (ID_with_null),
|
||||
INDEX idx2 (ID_better)
|
||||
);
|
||||
INSERT INTO t1 VALUES (1,1), (2,1), (null,3), (null,3), (null,3), (null,3);
|
||||
INSERT INTO t1 SELECT * FROM t1 WHERE ID_with_null IS NULL;
|
||||
INSERT INTO t1 SELECT * FROM t1 WHERE ID_with_null IS NULL;
|
||||
INSERT INTO t1 SELECT * FROM t1 WHERE ID_with_null IS NULL;
|
||||
INSERT INTO t1 SELECT * FROM t1 WHERE ID_with_null IS NULL;
|
||||
INSERT INTO t1 SELECT * FROM t1 WHERE ID_with_null IS NULL;
|
||||
SELECT COUNT(*) FROM t1 WHERE ID_with_null IS NULL;
|
||||
COUNT(*)
|
||||
128
|
||||
SELECT COUNT(*) FROM t1 WHERE ID_better=1;
|
||||
COUNT(*)
|
||||
2
|
||||
EXPLAIN SELECT * FROM t1 WHERE ID_better=1 AND ID_with_null IS NULL;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref idx1,idx2 idx2 4 const 1 Using where
|
||||
DROP INDEX idx1 ON t1;
|
||||
CREATE UNIQUE INDEX idx1 ON t1(ID_with_null);
|
||||
EXPLAIN SELECT * FROM t1 WHERE ID_better=1 AND ID_with_null IS NULL;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref idx1,idx2 idx2 4 const 1 Using where
|
||||
DROP TABLE t1;
|
||||
CREATE TABLE t1 (
|
||||
ID1_with_null int NULL,
|
||||
ID2_with_null int NULL,
|
||||
ID_better int NOT NULL,
|
||||
INDEX idx1 (ID1_with_null, ID2_with_null),
|
||||
INDEX idx2 (ID_better)
|
||||
);
|
||||
INSERT INTO t1 VALUES (1,1,1), (2,2,1), (3,null,3), (null,3,3), (null,null,3),
|
||||
(3,null,3), (null,3,3), (null,null,3), (3,null,3), (null,3,3), (null,null,3);
|
||||
INSERT INTO t1 SELECT * FROM t1 WHERE ID1_with_null IS NULL;
|
||||
INSERT INTO t1 SELECT * FROM t1 WHERE ID2_with_null IS NULL;
|
||||
INSERT INTO t1 SELECT * FROM t1 WHERE ID1_with_null IS NULL;
|
||||
INSERT INTO t1 SELECT * FROM t1 WHERE ID2_with_null IS NULL;
|
||||
INSERT INTO t1 SELECT * FROM t1 WHERE ID1_with_null IS NULL;
|
||||
INSERT INTO t1 SELECT * FROM t1 WHERE ID2_with_null IS NULL;
|
||||
SELECT COUNT(*) FROM t1 WHERE ID1_with_null IS NULL AND ID2_with_null=3;
|
||||
COUNT(*)
|
||||
24
|
||||
SELECT COUNT(*) FROM t1 WHERE ID1_with_null=3 AND ID2_with_null IS NULL;
|
||||
COUNT(*)
|
||||
24
|
||||
SELECT COUNT(*) FROM t1 WHERE ID1_with_null IS NULL AND ID2_with_null IS NULL;
|
||||
COUNT(*)
|
||||
192
|
||||
SELECT COUNT(*) FROM t1 WHERE ID_better=1;
|
||||
COUNT(*)
|
||||
2
|
||||
EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null IS NULL AND ID2_with_null=3 ;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref idx1,idx2 idx2 4 const 1 Using where
|
||||
EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null=3 AND ID2_with_null=3 IS NULL ;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref idx1,idx2 idx2 4 const 1 Using where
|
||||
EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null IS NULL AND ID2_with_null IS NULL;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref idx1,idx2 idx2 4 const 1 Using where
|
||||
DROP INDEX idx1 ON t1;
|
||||
CREATE UNIQUE INDEX idx1 ON t1(ID1_with_null,ID2_with_null);
|
||||
EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null IS NULL AND ID2_with_null=3 ;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref idx1,idx2 idx2 4 const 1 Using where
|
||||
EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null=3 AND ID2_with_null IS NULL ;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref idx1,idx2 idx2 4 const 1 Using where
|
||||
EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null IS NULL AND ID2_with_null IS NULL;
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref idx1,idx2 idx2 4 const 1 Using where
|
||||
EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null IS NULL AND
|
||||
(ID2_with_null=1 OR ID2_with_null=2);
|
||||
id select_type table type possible_keys key key_len ref rows Extra
|
||||
1 SIMPLE t1 ref idx1,idx2 idx2 4 const 1 Using where
|
||||
DROP TABLE t1;
|
||||
|
|
|
@ -3133,3 +3133,77 @@ SELECT * FROM t1 LIMIT 2, -1;
|
|||
|
||||
DROP TABLE t1;
|
||||
|
||||
#
|
||||
# 25407: wrong estimate of NULL keys for unique indexes
|
||||
#
|
||||
|
||||
CREATE TABLE t1 (
|
||||
ID_with_null int NULL,
|
||||
ID_better int NOT NULL,
|
||||
INDEX idx1 (ID_with_null),
|
||||
INDEX idx2 (ID_better)
|
||||
);
|
||||
|
||||
INSERT INTO t1 VALUES (1,1), (2,1), (null,3), (null,3), (null,3), (null,3);
|
||||
INSERT INTO t1 SELECT * FROM t1 WHERE ID_with_null IS NULL;
|
||||
INSERT INTO t1 SELECT * FROM t1 WHERE ID_with_null IS NULL;
|
||||
INSERT INTO t1 SELECT * FROM t1 WHERE ID_with_null IS NULL;
|
||||
INSERT INTO t1 SELECT * FROM t1 WHERE ID_with_null IS NULL;
|
||||
INSERT INTO t1 SELECT * FROM t1 WHERE ID_with_null IS NULL;
|
||||
|
||||
SELECT COUNT(*) FROM t1 WHERE ID_with_null IS NULL;
|
||||
SELECT COUNT(*) FROM t1 WHERE ID_better=1;
|
||||
|
||||
EXPLAIN SELECT * FROM t1 WHERE ID_better=1 AND ID_with_null IS NULL;
|
||||
|
||||
DROP INDEX idx1 ON t1;
|
||||
CREATE UNIQUE INDEX idx1 ON t1(ID_with_null);
|
||||
|
||||
EXPLAIN SELECT * FROM t1 WHERE ID_better=1 AND ID_with_null IS NULL;
|
||||
|
||||
DROP TABLE t1;
|
||||
|
||||
CREATE TABLE t1 (
|
||||
ID1_with_null int NULL,
|
||||
ID2_with_null int NULL,
|
||||
ID_better int NOT NULL,
|
||||
INDEX idx1 (ID1_with_null, ID2_with_null),
|
||||
INDEX idx2 (ID_better)
|
||||
);
|
||||
|
||||
INSERT INTO t1 VALUES (1,1,1), (2,2,1), (3,null,3), (null,3,3), (null,null,3),
|
||||
(3,null,3), (null,3,3), (null,null,3), (3,null,3), (null,3,3), (null,null,3);
|
||||
|
||||
INSERT INTO t1 SELECT * FROM t1 WHERE ID1_with_null IS NULL;
|
||||
INSERT INTO t1 SELECT * FROM t1 WHERE ID2_with_null IS NULL;
|
||||
INSERT INTO t1 SELECT * FROM t1 WHERE ID1_with_null IS NULL;
|
||||
INSERT INTO t1 SELECT * FROM t1 WHERE ID2_with_null IS NULL;
|
||||
INSERT INTO t1 SELECT * FROM t1 WHERE ID1_with_null IS NULL;
|
||||
INSERT INTO t1 SELECT * FROM t1 WHERE ID2_with_null IS NULL;
|
||||
|
||||
SELECT COUNT(*) FROM t1 WHERE ID1_with_null IS NULL AND ID2_with_null=3;
|
||||
SELECT COUNT(*) FROM t1 WHERE ID1_with_null=3 AND ID2_with_null IS NULL;
|
||||
SELECT COUNT(*) FROM t1 WHERE ID1_with_null IS NULL AND ID2_with_null IS NULL;
|
||||
SELECT COUNT(*) FROM t1 WHERE ID_better=1;
|
||||
|
||||
EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null IS NULL AND ID2_with_null=3 ;
|
||||
EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null=3 AND ID2_with_null=3 IS NULL ;
|
||||
EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null IS NULL AND ID2_with_null IS NULL;
|
||||
|
||||
DROP INDEX idx1 ON t1;
|
||||
CREATE UNIQUE INDEX idx1 ON t1(ID1_with_null,ID2_with_null);
|
||||
|
||||
EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null IS NULL AND ID2_with_null=3 ;
|
||||
EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null=3 AND ID2_with_null IS NULL ;
|
||||
EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null IS NULL AND ID2_with_null IS NULL;
|
||||
EXPLAIN SELECT * FROM t1
|
||||
WHERE ID_better=1 AND ID1_with_null IS NULL AND
|
||||
(ID2_with_null=1 OR ID2_with_null=2);
|
||||
|
||||
DROP TABLE t1;
|
||||
|
|
|
@ -193,6 +193,8 @@ public:
|
|||
}
|
||||
inline void merge_flags(SEL_ARG *arg) { maybe_flag|=arg->maybe_flag; }
|
||||
inline void maybe_smaller() { maybe_flag=1; }
|
||||
/* Return true iff it's a single-point null interval */
|
||||
inline bool is_null_interval() { return maybe_null && max_value[0] == 1; }
|
||||
inline int cmp_min_to_min(SEL_ARG* arg)
|
||||
{
|
||||
return sel_cmp(field,min_value, arg->min_value, min_flag, arg->min_flag);
|
||||
|
@ -452,6 +454,7 @@ typedef struct st_qsel_param {
|
|||
bool is_ror_scan;
|
||||
/* Number of ranges in the last checked tree->key */
|
||||
uint n_ranges;
|
||||
uint8 first_null_comp; /* first null component if any, 0 - otherwise */
|
||||
} PARAM;
|
||||
|
||||
class TABLE_READ_PLAN;
|
||||
|
@ -5619,6 +5622,7 @@ check_quick_select(PARAM *param,uint idx,SEL_ARG *tree)
|
|||
DBUG_ENTER("check_quick_select");
|
||||
|
||||
param->is_ror_scan= FALSE;
|
||||
param->first_null_comp= 0;
|
||||
|
||||
if (!tree)
|
||||
DBUG_RETURN(HA_POS_ERROR); // Can't use it
|
||||
|
@ -5710,6 +5714,7 @@ check_quick_keys(PARAM *param,uint idx,SEL_ARG *key_tree,
|
|||
ha_rows records=0, tmp;
|
||||
uint tmp_min_flag, tmp_max_flag, keynr, min_key_length, max_key_length;
|
||||
char *tmp_min_key, *tmp_max_key;
|
||||
uint8 save_first_null_comp= param->first_null_comp;
|
||||
|
||||
param->max_key_part=max(param->max_key_part,key_tree->part);
|
||||
if (key_tree->left != &null_element)
|
||||
|
@ -5747,6 +5752,9 @@ check_quick_keys(PARAM *param,uint idx,SEL_ARG *key_tree,
|
|||
param->is_ror_scan= FALSE;
|
||||
}
|
||||
|
||||
if (!param->first_null_comp && key_tree->is_null_interval())
|
||||
param->first_null_comp= key_tree->part+1;
|
||||
|
||||
if (key_tree->next_key_part &&
|
||||
key_tree->next_key_part->part == key_tree->part+1 &&
|
||||
key_tree->next_key_part->type == SEL_ARG::KEY_RANGE)
|
||||
|
@ -5790,7 +5798,8 @@ check_quick_keys(PARAM *param,uint idx,SEL_ARG *key_tree,
|
|||
(param->table->key_info[keynr].flags & (HA_NOSAME | HA_END_SPACE_KEY)) ==
|
||||
HA_NOSAME &&
|
||||
min_key_length == max_key_length &&
|
||||
!memcmp(param->min_key,param->max_key,min_key_length))
|
||||
!memcmp(param->min_key,param->max_key,min_key_length) &&
|
||||
!param->first_null_comp)
|
||||
{
|
||||
tmp=1; // Max one record
|
||||
param->n_ranges++;
|
||||
|
@ -5865,6 +5874,7 @@ check_quick_keys(PARAM *param,uint idx,SEL_ARG *key_tree,
|
|||
return tmp;
|
||||
records+=tmp;
|
||||
}
|
||||
param->first_null_comp= save_first_null_comp;
|
||||
return records;
|
||||
}
|
||||
|
||||
|
|
Loading…
Reference in a new issue