Skip to content

Commit c21d462

Browse files
committed
Merge branch 'bb-11.4-serg' into bb-11.8-serg
2 parents 5ce9a03 + aa6a2e6 commit c21d462

28 files changed

+625
-429
lines changed

mysql-test/main/max_session_mem_used.result

Lines changed: 82 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -46,3 +46,85 @@ REPAIR LOCAL TABLE t1;
4646
DROP TABLE t1;
4747
SET max_session_mem_used=default;
4848
# End of 10.6 tests
49+
#
50+
# MDEV-37489: SIGSEGV in get_param_default_value | store_schema_params
51+
#
52+
CREATE OR REPLACE PROCEDURE p0 (x INT DEFAULT func())
53+
BEGIN
54+
SELECT x;
55+
END;
56+
//
57+
SET SESSION max_session_mem_used=8192;
58+
CALL p0();
59+
ERROR HY000: The MariaDB server is running with the --max-session-mem-used=8192 option so it cannot execute this statement
60+
SET @@max_session_mem_used=DEFAULT;
61+
CALL p0();
62+
ERROR 42000: FUNCTION test.func does not exist
63+
SELECT * FROM information_schema.PARAMETERS where specific_name = 'p0';
64+
SPECIFIC_CATALOG SPECIFIC_SCHEMA SPECIFIC_NAME ORDINAL_POSITION PARAMETER_MODE PARAMETER_NAME DATA_TYPE CHARACTER_MAXIMUM_LENGTH CHARACTER_OCTET_LENGTH NUMERIC_PRECISION NUMERIC_SCALE DATETIME_PRECISION CHARACTER_SET_NAME COLLATION_NAME DTD_IDENTIFIER ROUTINE_TYPE
65+
def test p0 1 IN x int NULL NULL 10 0 NULL NULL NULL int(11) PROCEDURE
66+
# with func() defined
67+
CREATE FUNCTION func(x INT DEFAULT 10) RETURNS INT
68+
BEGIN
69+
RETURN x;
70+
END;
71+
//
72+
CREATE OR REPLACE PROCEDURE p0 (x INT DEFAULT func())
73+
BEGIN
74+
SELECT x;
75+
END;
76+
//
77+
SET SESSION max_session_mem_used=8192;
78+
CALL p0();
79+
ERROR HY000: The MariaDB server is running with the --max-session-mem-used=8192 option so it cannot execute this statement
80+
SET @@max_session_mem_used=DEFAULT;
81+
CALL p0();
82+
x
83+
10
84+
SELECT * FROM information_schema.PARAMETERS where specific_name = 'p0';
85+
SPECIFIC_CATALOG SPECIFIC_SCHEMA SPECIFIC_NAME ORDINAL_POSITION PARAMETER_MODE PARAMETER_NAME DATA_TYPE CHARACTER_MAXIMUM_LENGTH CHARACTER_OCTET_LENGTH NUMERIC_PRECISION NUMERIC_SCALE DATETIME_PRECISION CHARACTER_SET_NAME COLLATION_NAME DTD_IDENTIFIER ROUTINE_TYPE
86+
def test p0 1 IN x int NULL NULL 10 0 NULL NULL NULL int(11) PROCEDURE
87+
# with multiple functions
88+
CREATE FUNCTION func2(x INT DEFAULT 10) RETURNS INT
89+
BEGIN
90+
RETURN x;
91+
END;
92+
//
93+
CREATE OR REPLACE PROCEDURE p0 (x INT DEFAULT func(), y INT DEFAULT func2())
94+
BEGIN
95+
SELECT x, y;
96+
END;
97+
//
98+
SET SESSION max_session_mem_used=8192;
99+
CALL p0();
100+
ERROR HY000: The MariaDB server is running with the --max-session-mem-used=8192 option so it cannot execute this statement
101+
SET @@max_session_mem_used=DEFAULT;
102+
CALL p0();
103+
x y
104+
10 10
105+
SELECT * FROM information_schema.PARAMETERS where specific_name = 'p0';
106+
SPECIFIC_CATALOG SPECIFIC_SCHEMA SPECIFIC_NAME ORDINAL_POSITION PARAMETER_MODE PARAMETER_NAME DATA_TYPE CHARACTER_MAXIMUM_LENGTH CHARACTER_OCTET_LENGTH NUMERIC_PRECISION NUMERIC_SCALE DATETIME_PRECISION CHARACTER_SET_NAME COLLATION_NAME DTD_IDENTIFIER ROUTINE_TYPE
107+
def test p0 1 IN x int NULL NULL 10 0 NULL NULL NULL int(11) PROCEDURE
108+
def test p0 2 IN y int NULL NULL 10 0 NULL NULL NULL int(11) PROCEDURE
109+
# with function and constant default param
110+
CREATE OR REPLACE PROCEDURE p0 (x INT DEFAULT func(), y INT DEFAULT func2(), z INT DEFAULT 10)
111+
BEGIN
112+
SELECT x, y, z;
113+
END;
114+
//
115+
SET SESSION max_session_mem_used=8192;
116+
CALL p0();
117+
ERROR HY000: The MariaDB server is running with the --max-session-mem-used=8192 option so it cannot execute this statement
118+
SET @@max_session_mem_used=DEFAULT;
119+
CALL p0();
120+
x y z
121+
10 10 10
122+
SELECT * FROM information_schema.PARAMETERS where specific_name = 'p0';
123+
SPECIFIC_CATALOG SPECIFIC_SCHEMA SPECIFIC_NAME ORDINAL_POSITION PARAMETER_MODE PARAMETER_NAME DATA_TYPE CHARACTER_MAXIMUM_LENGTH CHARACTER_OCTET_LENGTH NUMERIC_PRECISION NUMERIC_SCALE DATETIME_PRECISION CHARACTER_SET_NAME COLLATION_NAME DTD_IDENTIFIER ROUTINE_TYPE
124+
def test p0 1 IN x int NULL NULL 10 0 NULL NULL NULL int(11) PROCEDURE
125+
def test p0 2 IN y int NULL NULL 10 0 NULL NULL NULL int(11) PROCEDURE
126+
def test p0 3 IN z int NULL NULL 10 0 NULL NULL NULL int(11) PROCEDURE
127+
DROP PROCEDURE p0;
128+
DROP FUNCTION func;
129+
DROP FUNCTION func2;
130+
# End of 11.8 tests

mysql-test/main/max_session_mem_used.test

Lines changed: 94 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -83,3 +83,97 @@ DROP TABLE t1;
8383
SET max_session_mem_used=default;
8484

8585
--echo # End of 10.6 tests
86+
87+
--echo #
88+
--echo # MDEV-37489: SIGSEGV in get_param_default_value | store_schema_params
89+
--echo #
90+
91+
--DELIMITER //
92+
CREATE OR REPLACE PROCEDURE p0 (x INT DEFAULT func())
93+
BEGIN
94+
SELECT x;
95+
END;
96+
//
97+
--DELIMITER ;
98+
99+
SET SESSION max_session_mem_used=8192;
100+
--ERROR ER_OPTION_PREVENTS_STATEMENT
101+
CALL p0();
102+
103+
SET @@max_session_mem_used=DEFAULT;
104+
--ERROR ER_SP_DOES_NOT_EXIST
105+
CALL p0();
106+
107+
SELECT * FROM information_schema.PARAMETERS where specific_name = 'p0';
108+
109+
--echo # with func() defined
110+
--DELIMITER //
111+
CREATE FUNCTION func(x INT DEFAULT 10) RETURNS INT
112+
BEGIN
113+
RETURN x;
114+
END;
115+
//
116+
117+
CREATE OR REPLACE PROCEDURE p0 (x INT DEFAULT func())
118+
BEGIN
119+
SELECT x;
120+
END;
121+
//
122+
--DELIMITER ;
123+
124+
SET SESSION max_session_mem_used=8192;
125+
--ERROR ER_OPTION_PREVENTS_STATEMENT
126+
CALL p0();
127+
128+
SET @@max_session_mem_used=DEFAULT;
129+
CALL p0();
130+
131+
SELECT * FROM information_schema.PARAMETERS where specific_name = 'p0';
132+
133+
--echo # with multiple functions
134+
--DELIMITER //
135+
CREATE FUNCTION func2(x INT DEFAULT 10) RETURNS INT
136+
BEGIN
137+
RETURN x;
138+
END;
139+
//
140+
141+
CREATE OR REPLACE PROCEDURE p0 (x INT DEFAULT func(), y INT DEFAULT func2())
142+
BEGIN
143+
SELECT x, y;
144+
END;
145+
//
146+
--DELIMITER ;
147+
148+
SET SESSION max_session_mem_used=8192;
149+
--ERROR ER_OPTION_PREVENTS_STATEMENT
150+
CALL p0();
151+
152+
SET @@max_session_mem_used=DEFAULT;
153+
CALL p0();
154+
155+
SELECT * FROM information_schema.PARAMETERS where specific_name = 'p0';
156+
157+
--echo # with function and constant default param
158+
--DELIMITER //
159+
CREATE OR REPLACE PROCEDURE p0 (x INT DEFAULT func(), y INT DEFAULT func2(), z INT DEFAULT 10)
160+
BEGIN
161+
SELECT x, y, z;
162+
END;
163+
//
164+
--DELIMITER ;
165+
166+
SET SESSION max_session_mem_used=8192;
167+
--ERROR ER_OPTION_PREVENTS_STATEMENT
168+
CALL p0();
169+
170+
SET @@max_session_mem_used=DEFAULT;
171+
CALL p0();
172+
173+
SELECT * FROM information_schema.PARAMETERS where specific_name = 'p0';
174+
175+
DROP PROCEDURE p0;
176+
DROP FUNCTION func;
177+
DROP FUNCTION func2;
178+
179+
--echo # End of 11.8 tests

mysql-test/main/mysqld--help.result

Lines changed: 3 additions & 2 deletions
Original file line numberDiff line numberDiff line change
@@ -775,8 +775,9 @@ The following specify which files/extra groups are read (specified before remain
775775
Number of seconds to wait for a block to be written to a
776776
connection before aborting the write
777777
--new-mode=name Used to introduce new behavior to existing MariaDB
778-
versions. Any combination of: FIX_DISK_TMPTABLE_COSTS, or
779-
ALL to set all combinations
778+
versions. Any combination of: FIX_DISK_TMPTABLE_COSTS,
779+
FIX_INDEX_STATS_FOR_ALL_NULLS, or ALL to set all
780+
combinations
780781
--note-verbosity=name
781782
Verbosity level for note-warnings given to the user. See
782783
also @@sql_notes. Any combination of: basic,
Lines changed: 158 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,158 @@
1+
SET @session_start_value = @@new_mode;
2+
# Small driving table
3+
CREATE TABLE t1 (a INT, b INT);
4+
INSERT INTO t1 VALUES (1, 1), (2, 2000),(3,300);
5+
ANALYZE TABLE t1 PERSISTENT FOR ALL;
6+
Table Op Msg_type Msg_text
7+
test.t1 analyze status Engine-independent statistics collected
8+
test.t1 analyze status OK
9+
# Table that will be accessed by an index lookup (`ref` access)
10+
CREATE TABLE t2 (a INT, b INT, KEY key_b(b));
11+
# All t11.b values are NULL
12+
INSERT INTO t2 SELECT seq/100, NULL FROM seq_1_to_1000;
13+
ANALYZE TABLE t2 PERSISTENT FOR ALL;
14+
Table Op Msg_type Msg_text
15+
test.t2 analyze status Engine-independent statistics collected
16+
test.t2 analyze status Table is already up to date
17+
SET @@new_mode = "FIX_INDEX_STATS_FOR_ALL_NULLS";
18+
# NULL-rejecting equality t1.b = t2.b will not return any matches
19+
# because all values of t2.b are NULL. So "rows" = 1 for t2 where 1 is
20+
# a special value meaning "very few" rows
21+
EXPLAIN EXTENDED SELECT * FROM t1 JOIN t2 ON t1.a = t2.a AND t1.b = t2.b;
22+
id select_type table type possible_keys key key_len ref rows filtered Extra
23+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 Using where
24+
1 SIMPLE t2 ref key_b key_b 5 test.t1.b 1 100.00 Using where
25+
Warnings:
26+
Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t1` join `test`.`t2` where `test`.`t2`.`a` = `test`.`t1`.`a` and `test`.`t2`.`b` = `test`.`t1`.`b`
27+
# However, rows estimation for not NULL-rejecting conditions
28+
# must not be affected ("rows" > 1 is expected)
29+
EXPLAIN EXTENDED SELECT * FROM t1 JOIN t2 ON t1.a = t2.a AND t1.b <=> t2.b;
30+
id select_type table type possible_keys key key_len ref rows filtered Extra
31+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00
32+
1 SIMPLE t2 ref key_b key_b 5 test.t1.b 11 100.00 Using index condition; Using where
33+
Warnings:
34+
Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t1` join `test`.`t2` where `test`.`t2`.`a` = `test`.`t1`.`a` and `test`.`t1`.`b` <=> `test`.`t2`.`b`
35+
# Insert some non-NULL values and re-collect the stats
36+
INSERT INTO t2 SELECT 1, 1 FROM seq_1_to_100;
37+
ANALYZE TABLE t2 PERSISTENT FOR COLUMNS (b) INDEXES (key_b);
38+
Table Op Msg_type Msg_text
39+
test.t2 analyze status Engine-independent statistics collected
40+
test.t2 analyze status OK
41+
EXPLAIN EXTENDED SELECT * FROM t1 JOIN t2 ON t1.a = t2.a AND t1.b = t2.b;
42+
id select_type table type possible_keys key key_len ref rows filtered Extra
43+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 Using where
44+
1 SIMPLE t2 ref key_b key_b 5 test.t1.b 100 100.00 Using where
45+
Warnings:
46+
Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t1` join `test`.`t2` where `test`.`t2`.`a` = `test`.`t1`.`a` and `test`.`t2`.`b` = `test`.`t1`.`b`
47+
# Test composite index for two columns. Key prefix is used for access
48+
CREATE TABLE t3 (a INT, b INT, KEY key_ab(a,b));
49+
# All t3.b values are NULL
50+
INSERT INTO t3 SELECT seq/100, NULL FROM seq_1_to_1000;
51+
ANALYZE TABLE t3 PERSISTENT FOR COLUMNS(b) INDEXES(key_ab);
52+
Table Op Msg_type Msg_text
53+
test.t3 analyze status Engine-independent statistics collected
54+
test.t3 analyze status Table is already up to date
55+
# NULL-rejecting equality t1.b = t3.b, same as above.
56+
# "rows" must be estimated to 1
57+
EXPLAIN EXTENDED SELECT * FROM t1 JOIN t3 ON t1.a = t3.a AND t1.b = t3.b;
58+
id select_type table type possible_keys key key_len ref rows filtered Extra
59+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 Using where
60+
1 SIMPLE t3 ref key_ab key_ab 10 test.t1.a,test.t1.b 1 100.00 Using index
61+
Warnings:
62+
Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t3`.`a` AS `a`,`test`.`t3`.`b` AS `b` from `test`.`t1` join `test`.`t3` where `test`.`t3`.`a` = `test`.`t1`.`a` and `test`.`t3`.`b` = `test`.`t1`.`b`
63+
# Rows estimation for not NULL-rejecting conditions are not affected
64+
# ("rows" > 1 is expected)
65+
EXPLAIN EXTENDED SELECT * FROM t1 JOIN t3 ON t1.a = t3.a;
66+
id select_type table type possible_keys key key_len ref rows filtered Extra
67+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 Using where
68+
1 SIMPLE t3 ref key_ab key_ab 5 test.t1.a 90 100.00 Using index
69+
Warnings:
70+
Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t3`.`a` AS `a`,`test`.`t3`.`b` AS `b` from `test`.`t1` join `test`.`t3` where `test`.`t3`.`a` = `test`.`t1`.`a`
71+
EXPLAIN EXTENDED SELECT * FROM t1 JOIN t3 ON t1.a = t3.a AND t1.b <=> t3.b;
72+
id select_type table type possible_keys key key_len ref rows filtered Extra
73+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 Using where
74+
1 SIMPLE t3 ref key_ab key_ab 10 test.t1.a,test.t1.b 11 100.00 Using where; Using index
75+
Warnings:
76+
Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t3`.`a` AS `a`,`test`.`t3`.`b` AS `b` from `test`.`t1` join `test`.`t3` where `test`.`t3`.`a` = `test`.`t1`.`a` and `test`.`t1`.`b` <=> `test`.`t3`.`b`
77+
EXPLAIN EXTENDED SELECT * FROM t1 JOIN t3 ON t1.a = t3.a AND t3.b is NULL;
78+
id select_type table type possible_keys key key_len ref rows filtered Extra
79+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 Using where
80+
1 SIMPLE t3 ref key_ab key_ab 10 test.t1.a,const 11 100.00 Using where; Using index
81+
Warnings:
82+
Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t3`.`a` AS `a`,`test`.`t3`.`b` AS `b` from `test`.`t1` join `test`.`t3` where `test`.`t3`.`a` = `test`.`t1`.`a` and `test`.`t3`.`b` is null
83+
# In the old mode (null-aware estimation is not enabled), "rows" > 1
84+
SET @@new_mode = "";
85+
EXPLAIN EXTENDED SELECT * FROM t1 JOIN t2 ON t1.a = t2.a AND t1.b = t2.b;
86+
id select_type table type possible_keys key key_len ref rows filtered Extra
87+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 Using where
88+
1 SIMPLE t2 ref key_b key_b 5 test.t1.b 100 100.00 Using where
89+
Warnings:
90+
Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t2`.`a` AS `a`,`test`.`t2`.`b` AS `b` from `test`.`t1` join `test`.`t2` where `test`.`t2`.`a` = `test`.`t1`.`a` and `test`.`t2`.`b` = `test`.`t1`.`b`
91+
# Insert some non-NULL values and re-collect the stats
92+
INSERT INTO t3 SELECT 1, 1 FROM seq_1_to_100;
93+
ANALYZE TABLE t3 PERSISTENT FOR COLUMNS (b) INDEXES (key_ab);
94+
Table Op Msg_type Msg_text
95+
test.t3 analyze status Engine-independent statistics collected
96+
test.t3 analyze status OK
97+
SET @@new_mode = "FIX_INDEX_STATS_FOR_ALL_NULLS";
98+
EXPLAIN EXTENDED SELECT * FROM t1 JOIN t3 ON t1.a = t3.a AND t1.b = t3.b;
99+
id select_type table type possible_keys key key_len ref rows filtered Extra
100+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 Using where
101+
1 SIMPLE t3 ref key_ab key_ab 10 test.t1.a,test.t1.b 100 100.00 Using index
102+
Warnings:
103+
Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t3`.`a` AS `a`,`test`.`t3`.`b` AS `b` from `test`.`t1` join `test`.`t3` where `test`.`t3`.`a` = `test`.`t1`.`a` and `test`.`t3`.`b` = `test`.`t1`.`b`
104+
# Test composite index for 3 columns. Key prefix is used for access
105+
CREATE TABLE t4 (a INT, b INT, c INT, KEY key_abc(a,b,c));
106+
# All t3.b values are NULL
107+
INSERT INTO t4 SELECT seq/10, NULL, seq/10 FROM seq_1_to_1000;
108+
ANALYZE TABLE t4 PERSISTENT FOR COLUMNS(b) INDEXES(key_abc);
109+
Table Op Msg_type Msg_text
110+
test.t4 analyze status Engine-independent statistics collected
111+
test.t4 analyze status Table is already up to date
112+
# NULL-rejecting equality t1.b = t3.b, same as above.
113+
# "rows" must be estimated to 1
114+
EXPLAIN EXTENDED SELECT * FROM t1 JOIN t4 ON t1.a = t4.a AND t1.b = t4.b;
115+
id select_type table type possible_keys key key_len ref rows filtered Extra
116+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 Using where
117+
1 SIMPLE t4 ref key_abc key_abc 10 test.t1.a,test.t1.b 1 100.00 Using index
118+
Warnings:
119+
Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t4`.`a` AS `a`,`test`.`t4`.`b` AS `b`,`test`.`t4`.`c` AS `c` from `test`.`t1` join `test`.`t4` where `test`.`t4`.`a` = `test`.`t1`.`a` and `test`.`t4`.`b` = `test`.`t1`.`b`
120+
EXPLAIN EXTENDED SELECT * FROM t1 JOIN t4 ON t1.a = t4.a AND t1.b = t4.b and t1.b = t4.c;
121+
id select_type table type possible_keys key key_len ref rows filtered Extra
122+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 Using where
123+
1 SIMPLE t4 ref key_abc key_abc 15 test.t1.a,test.t1.b,test.t1.b 1 100.00 Using index
124+
Warnings:
125+
Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t4`.`a` AS `a`,`test`.`t4`.`b` AS `b`,`test`.`t4`.`c` AS `c` from `test`.`t1` join `test`.`t4` where `test`.`t4`.`a` = `test`.`t1`.`a` and `test`.`t4`.`b` = `test`.`t1`.`b` and `test`.`t4`.`c` = `test`.`t1`.`b`
126+
# "rows" expected to be > 1
127+
EXPLAIN EXTENDED SELECT * FROM t1 JOIN t4 ON t1.a = t4.a;
128+
id select_type table type possible_keys key key_len ref rows filtered Extra
129+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 Using where
130+
1 SIMPLE t4 ref key_abc key_abc 5 test.t1.a 9 100.00 Using index
131+
Warnings:
132+
Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t4`.`a` AS `a`,`test`.`t4`.`b` AS `b`,`test`.`t4`.`c` AS `c` from `test`.`t1` join `test`.`t4` where `test`.`t4`.`a` = `test`.`t1`.`a`
133+
EXPLAIN EXTENDED SELECT * FROM t1 JOIN t4 ON t1.a = t4.a AND t1.b <=> t4.c;
134+
id select_type table type possible_keys key key_len ref rows filtered Extra
135+
1 SIMPLE t1 ALL NULL NULL NULL NULL 3 100.00 Using where
136+
1 SIMPLE t4 ref key_abc key_abc 5 test.t1.a 9 100.00 Using where; Using index
137+
Warnings:
138+
Note 1003 select `test`.`t1`.`a` AS `a`,`test`.`t1`.`b` AS `b`,`test`.`t4`.`a` AS `a`,`test`.`t4`.`b` AS `b`,`test`.`t4`.`c` AS `c` from `test`.`t1` join `test`.`t4` where `test`.`t4`.`a` = `test`.`t1`.`a` and `test`.`t1`.`b` <=> `test`.`t4`.`c`
139+
DROP TABLE t1, t2, t3, t4;
140+
# Test for partially covered column
141+
CREATE TABLE t1 (a VARCHAR(10));
142+
INSERT INTO t1 SELECT seq FROM seq_1_to_10;
143+
CREATE TABLE t2 (
144+
a VARCHAR(10),
145+
b VARCHAR(10),
146+
INDEX i1(a, b(5))
147+
);
148+
INSERT INTO t2 SELECT seq, NULL FROM seq_1_to_1000;
149+
ANALYZE TABLE t2 PERSISTENT FOR COLUMNS (b) INDEXES (i1);
150+
Table Op Msg_type Msg_text
151+
test.t2 analyze status Engine-independent statistics collected
152+
test.t2 analyze status Table is already up to date
153+
EXPLAIN SELECT * FROM t1, t2 WHERE t2.a=t1.a AND t2.b=t1.a;
154+
id select_type table type possible_keys key key_len ref rows Extra
155+
1 SIMPLE t1 ALL NULL NULL NULL NULL 10 Using where
156+
1 SIMPLE t2 ref i1 i1 66 test.t1.a,test.t1.a 1 Using where
157+
SET @@new_mode = @session_start_value;
158+
DROP TABLE t1, t2;

0 commit comments

Comments
 (0)