Skip to content

Commit 8916aee

Browse files
committed
MDEV-37723: TPROC-H Query4 much slower in 11.4 than in 10.11
(Patch provided by Monty, Testcase by Rex Johnston) get_tmp_table_costs() computes the cost of using a temporary (work table) for certain cases, including semi-join subquery materialization. The computed cost value was very low, it used this formula: key_lookup_cost * (disk_read_ratio= 0.02) Use the correct formula: key_lookup_cost // Index lookup is always done + disk_read_cost * disk_read_ratio disk_read_cost is incurred when the lookup has to go to disk. We assume this doesn't occur for every lookup. It happens only with disk_read_ratio=0.02 frequency. The fix is controlled by @@new_mode='FIX_DISK_TMPTABLE_COSTS' flag. It is OFF by default in this patch.
1 parent f7387cb commit 8916aee

File tree

5 files changed

+210
-40
lines changed

5 files changed

+210
-40
lines changed

mysql-test/main/costs.result

Lines changed: 145 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -124,3 +124,148 @@ id select_type table type possible_keys key key_len ref rows Extra
124124
1 SIMPLE t1 range l_suppkey l_suppkey 10 NULL 1 Using where; Using index
125125
drop table t1;
126126
set global InnoDB.optimizer_disk_read_ratio=@save;
127+
#
128+
# MDEV-37723 In MDEV-36861, analyze Q4
129+
# Alter disk based tmp table lookup cost formula
130+
#
131+
create table t1 (a int primary key,
132+
b date, c char(15),
133+
d blob,
134+
key t1_ix1 (b)) ENGINE= InnoDB;
135+
create table t2 (e int not null,
136+
f int not null,
137+
g date, h date,
138+
primary key (e, f)) ENGINE= InnoDB;
139+
insert into t1 select seq, date('1993-06-01') + interval seq second,
140+
chr(65+mod(seq, 4)), NULL from seq_1_to_7000;
141+
insert into t2 select a.seq, b.seq, date('1993-06-01') + interval b.seq day,
142+
if (mod(a.seq,2), date('1993-06-01') + interval b.seq+1 day,
143+
date('1993-06-01') - interval b.seq-1 day)
144+
from seq_1_to_7000 a, seq_1_to_3 b;
145+
set
146+
@save_mhts= @@max_heap_table_size,
147+
@@max_heap_table_size=16384;
148+
set @save_new_mode=@@new_mode;
149+
set new_mode=CONCAT(@@new_mode, ',FIX_DISK_TMPTABLE_COSTS');
150+
# This should use: t1, FirstMatch(t2)
151+
explain format=json
152+
select c, count(*) as dc
153+
from t1
154+
where
155+
b >= date '1993-06-01' and b < date '1993-06-01' + interval '3' month and
156+
exists (select * from t2 where e = t1.a and g < h)
157+
group by c;
158+
EXPLAIN
159+
{
160+
"query_block": {
161+
"select_id": 1,
162+
"cost": 12.53886553,
163+
"filesort": {
164+
"sort_key": "t1.c",
165+
"temporary_table": {
166+
"nested_loop": [
167+
{
168+
"table": {
169+
"table_name": "t1",
170+
"access_type": "ALL",
171+
"possible_keys": ["PRIMARY", "t1_ix1"],
172+
"loops": 1,
173+
"rows": 7000,
174+
"cost": 1.1518548,
175+
"filtered": 100,
176+
"attached_condition": "t1.b >= DATE'1993-06-01' and t1.b < <cache>(DATE'1993-06-01' + interval '3' month)"
177+
}
178+
},
179+
{
180+
"table": {
181+
"table_name": "t2",
182+
"access_type": "ref",
183+
"possible_keys": ["PRIMARY"],
184+
"key": "PRIMARY",
185+
"key_length": "4",
186+
"used_key_parts": ["e"],
187+
"ref": ["test.t1.a"],
188+
"loops": 7000,
189+
"rows": 1,
190+
"cost": 6.7528092,
191+
"filtered": 100,
192+
"attached_condition": "t2.g < t2.h",
193+
"first_match": "t1"
194+
}
195+
}
196+
]
197+
}
198+
}
199+
}
200+
}
201+
SET new_mode = REPLACE(@@new_mode, 'FIX_DISK_TMPTABLE_COSTS', '');
202+
# This should use: t1, SJ-Materialization(t2)
203+
explain format=json
204+
select c, count(*) as dc
205+
from t1
206+
where
207+
b >= date '1993-06-01' and b < date '1993-06-01' + interval '3' month and
208+
exists (select * from t2 where e = t1.a and g < h)
209+
group by c;
210+
EXPLAIN
211+
{
212+
"query_block": {
213+
"select_id": 1,
214+
"cost": 12.39219425,
215+
"filesort": {
216+
"sort_key": "t1.c",
217+
"temporary_table": {
218+
"nested_loop": [
219+
{
220+
"table": {
221+
"table_name": "t1",
222+
"access_type": "ALL",
223+
"possible_keys": ["PRIMARY", "t1_ix1"],
224+
"loops": 1,
225+
"rows": 7000,
226+
"cost": 1.1518548,
227+
"filtered": 100,
228+
"attached_condition": "t1.b >= DATE'1993-06-01' and t1.b < <cache>(DATE'1993-06-01' + interval '3' month)"
229+
}
230+
},
231+
{
232+
"table": {
233+
"table_name": "<subquery2>",
234+
"access_type": "eq_ref",
235+
"possible_keys": ["distinct_key"],
236+
"key": "distinct_key",
237+
"key_length": "4",
238+
"used_key_parts": ["e"],
239+
"ref": ["func"],
240+
"rows": 1,
241+
"filtered": 100,
242+
"materialized": {
243+
"unique": 1,
244+
"query_block": {
245+
"select_id": 2,
246+
"nested_loop": [
247+
{
248+
"table": {
249+
"table_name": "t2",
250+
"access_type": "ALL",
251+
"possible_keys": ["PRIMARY"],
252+
"loops": 1,
253+
"rows": 21000,
254+
"cost": 3.4338548,
255+
"filtered": 100,
256+
"attached_condition": "t2.g < t2.h"
257+
}
258+
}
259+
]
260+
}
261+
}
262+
}
263+
}
264+
]
265+
}
266+
}
267+
}
268+
}
269+
set new_mode=@save_new_mode;
270+
set max_heap_table_size=@save_mhts;
271+
drop table t1, t2;

mysql-test/main/costs.test

Lines changed: 49 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -7,6 +7,7 @@
77

88
--source include/have_sequence.inc
99
--source include/have_innodb.inc
10+
--source include/innodb_stable_estimates.inc
1011

1112
create table t1 (a int primary key, b int, c int, d int, e int, key ba (b,a), key bda (b,d,a), key cba (c,b,a), key cb (c,b), key d (d)) engine=aria;
1213
insert into t1 select seq,seq,seq,seq,seq from seq_1_to_10;
@@ -114,3 +115,51 @@ explain select count(*) from test.t1 force index (l_suppkey) where l_suppkey >=
114115
drop table t1;
115116

116117
set global InnoDB.optimizer_disk_read_ratio=@save;
118+
119+
--echo #
120+
--echo # MDEV-37723 In MDEV-36861, analyze Q4
121+
--echo # Alter disk based tmp table lookup cost formula
122+
--echo #
123+
124+
create table t1 (a int primary key,
125+
b date, c char(15),
126+
d blob,
127+
key t1_ix1 (b)) ENGINE= InnoDB;
128+
create table t2 (e int not null,
129+
f int not null,
130+
g date, h date,
131+
primary key (e, f)) ENGINE= InnoDB;
132+
--disable_warnings
133+
insert into t1 select seq, date('1993-06-01') + interval seq second,
134+
chr(65+mod(seq, 4)), NULL from seq_1_to_7000;
135+
insert into t2 select a.seq, b.seq, date('1993-06-01') + interval b.seq day,
136+
if (mod(a.seq,2), date('1993-06-01') + interval b.seq+1 day,
137+
date('1993-06-01') - interval b.seq-1 day)
138+
from seq_1_to_7000 a, seq_1_to_3 b;
139+
140+
set
141+
@save_mhts= @@max_heap_table_size,
142+
@@max_heap_table_size=16384;
143+
144+
set @save_new_mode=@@new_mode;
145+
let $q=
146+
explain format=json
147+
select c, count(*) as dc
148+
from t1
149+
where
150+
b >= date '1993-06-01' and b < date '1993-06-01' + interval '3' month and
151+
exists (select * from t2 where e = t1.a and g < h)
152+
group by c;
153+
154+
set new_mode=CONCAT(@@new_mode, ',FIX_DISK_TMPTABLE_COSTS');
155+
--echo # This should use: t1, FirstMatch(t2)
156+
eval $q;
157+
158+
SET new_mode = REPLACE(@@new_mode, 'FIX_DISK_TMPTABLE_COSTS', '');
159+
160+
--echo # This should use: t1, SJ-Materialization(t2)
161+
eval $q;
162+
163+
set new_mode=@save_new_mode;
164+
set max_heap_table_size=@save_mhts;
165+
drop table t1, t2;

mysql-test/suite/sys_vars/r/new_mode.result

Lines changed: 0 additions & 16 deletions
Original file line numberDiff line numberDiff line change
@@ -57,22 +57,6 @@ SET @@global.new_mode = OFF;
5757
ERROR 42000: Variable 'new_mode' can't be set to the value of 'OFF'
5858
SET @@session.new_mode = OFF;
5959
ERROR 42000: Variable 'new_mode' can't be set to the value of 'OFF'
60-
SET @debug_dbug_safe = @@global.debug_dbug;
61-
SET @@global.debug_dbug = 'd,check_new_mode_mdev_37784';
62-
create table t1 (a int);
63-
insert into t1 values (1), (2);
64-
create table t2 (b int);
65-
insert into t2 values (3), (4);
66-
select * from t1 where a in (select b from t2);
67-
a
68-
SET @@new_mode = "FIX_DISK_TMPTABLE_COSTS";
69-
select * from t1 where a in (select b from t2);
70-
a
71-
Warnings:
72-
Note 1003 YES
73-
Note 1003 YES
74-
drop table t1, t2;
75-
SET @@global.debug_dbug = @debug_dbug_safe;
7660
SET @@global.new_mode = @global_start_value;
7761
SELECT @@global.new_mode;
7862
@@global.new_mode

mysql-test/suite/sys_vars/t/new_mode.test

Lines changed: 0 additions & 14 deletions
Original file line numberDiff line numberDiff line change
@@ -46,20 +46,6 @@ SET @@global.new_mode = OFF;
4646
--Error ER_WRONG_VALUE_FOR_VAR
4747
SET @@session.new_mode = OFF;
4848

49-
SET @debug_dbug_safe = @@global.debug_dbug;
50-
SET @@global.debug_dbug = 'd,check_new_mode_mdev_37784';
51-
52-
create table t1 (a int);
53-
insert into t1 values (1), (2);
54-
create table t2 (b int);
55-
insert into t2 values (3), (4);
56-
select * from t1 where a in (select b from t2);
57-
SET @@new_mode = "FIX_DISK_TMPTABLE_COSTS";
58-
select * from t1 where a in (select b from t2);
59-
drop table t1, t2;
60-
61-
SET @@global.debug_dbug = @debug_dbug_safe;
62-
6349
SET @@global.new_mode = @global_start_value;
6450
SELECT @@global.new_mode;
6551

sql/opt_subselect.cc

Lines changed: 16 additions & 10 deletions
Original file line numberDiff line numberDiff line change
@@ -2767,28 +2767,34 @@ get_tmp_table_costs(THD *thd, double row_count, uint row_size, bool blobs_used,
27672767
row_size+= sizeof(char*)*2;
27682768
row_size= MY_ALIGN(MY_MAX(row_size, sizeof(char*)) + 1, sizeof(char*));
27692769

2770-
/* remove this once TEST_NEW_MODE_FLAG is used elsewhere */
2771-
DBUG_EXECUTE_IF("check_new_mode_mdev_37784",
2772-
{
2773-
if (TEST_NEW_MODE_FLAG(thd, NEW_MODE_FIX_DISK_TMPTABLE_COSTS))
2774-
{
2775-
push_warning_printf(thd, Sql_condition::WARN_LEVEL_NOTE, ER_YES, "YES" );
2776-
}
2777-
});
2778-
27792770
if (row_count > thd->variables.max_heap_table_size / (double) row_size ||
27802771
blobs_used)
27812772
{
27822773
double row_copy_cost= (add_copy_cost ?
27832774
tmp_table_optimizer_costs.row_copy_cost :
27842775
0);
27852776
/* Disk based table */
2786-
cost.lookup= ((tmp_table_optimizer_costs.key_lookup_cost *
2777+
if (TEST_NEW_MODE_FLAG(thd, NEW_MODE_FIX_DISK_TMPTABLE_COSTS))
2778+
{
2779+
cost.lookup= ((tmp_table_optimizer_costs.key_lookup_cost +
2780+
tmp_table_optimizer_costs.disk_read_cost *
2781+
tmp_table_optimizer_costs.disk_read_ratio) +
2782+
row_copy_cost);
2783+
}
2784+
else
2785+
{
2786+
cost.lookup= ((tmp_table_optimizer_costs.key_lookup_cost *
27872787
tmp_table_optimizer_costs.disk_read_ratio) +
27882788
row_copy_cost);
2789+
}
2790+
/*
2791+
Don't have numbers for cost of writing, assume it's the same as cost
2792+
of reading for lack of a better number.
2793+
*/
27892794
cost.write= cost.lookup;
27902795
cost.create= DISK_TEMPTABLE_CREATE_COST;
27912796
cost.block_size= DISK_TEMPTABLE_BLOCK_SIZE;
2797+
/* The following costs are only used for table scans */
27922798
cost.avg_io_cost= tmp_table_optimizer_costs.disk_read_cost;
27932799
cost.cache_hit_ratio= tmp_table_optimizer_costs.disk_read_ratio;
27942800
}

0 commit comments

Comments
 (0)