Skip to content

Commit f2208d8

Browse files
author
Aditya A
committed
WL9513
Bug#23333990 PERSISTENT INDEX STATISTICS UPDATE BEFORE TRANSACTION IS COMMITTED PROBLEM By design stats estimation always reading uncommitted data. In this scenario an uncommitted transaction has deleted all rows in the table. In Innodb uncommitted delete records are marked as delete but not actually removed from Btree until the transaction has committed or a read view for the rows is present.While calculating persistent stats we were ignoring the delete marked records,since all the records are delete marked we were estimating the number of rows present in the table as zero which leads to bad plans in other transaction operating on the table. Fix Introduced a system variable called innodb_stats_include_delete_marked which when enabled includes delete marked records for stat calculations .
1 parent a5c67cb commit f2208d8

File tree

9 files changed

+309
-3
lines changed

9 files changed

+309
-3
lines changed
Lines changed: 90 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,90 @@
1+
#
2+
# Bug 23333990 PERSISTENT INDEX STATISTICS UPDATE BEFORE
3+
# TRANSACTION IS COMMITTED
4+
#
5+
"Test 1:- Uncommited delete test"
6+
CREATE TABLE t1 (id INT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY,
7+
val INT UNSIGNED NOT NULL,
8+
INDEX (val)) ENGINE=INNODB
9+
STATS_PERSISTENT=1,STATS_AUTO_RECALC=1;
10+
INSERT INTO t1 (val) VALUES (CEIL(RAND()*20));
11+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
12+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
13+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
14+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
15+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
16+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
17+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
18+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
19+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
20+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
21+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
22+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
23+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
24+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
25+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
26+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
27+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
28+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
29+
SELECT COUNT(*) FROM t1;
30+
COUNT(*)
31+
262144
32+
ANALYZE TABLE t1;
33+
Table Op Msg_type Msg_text
34+
test.t1 analyze status OK
35+
Connection 1
36+
START TRANSACTION;
37+
DELETE FROM t1;
38+
SELECT COUNT(*) FROM t1;
39+
Connection Default
40+
Test correctly estimates the number of rows as > 20000
41+
even when in other uncommmited transaction
42+
all rows have been deleted.
43+
Connection 1
44+
COUNT(*)
45+
0
46+
commit;
47+
Connection deafult
48+
Test 2:- Insert and rollback test
49+
CREATE TABLE t2 (id INT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY,
50+
val INT UNSIGNED NOT NULL,
51+
INDEX (val)) ENGINE=INNODB
52+
STATS_PERSISTENT=1,STATS_AUTO_RECALC=1;
53+
Connection 1
54+
START TRANSACTION;
55+
INSERT INTO t2 (val) VALUES (CEIL(RAND()*20));
56+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
57+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
58+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
59+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
60+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
61+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
62+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
63+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
64+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
65+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
66+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
67+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
68+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
69+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
70+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
71+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
72+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
73+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
74+
SELECT COUNT(*) FROM t2;
75+
Connection default
76+
select count(*) from t2;
77+
count(*)
78+
0
79+
Test correctly estimates the number of rows as > 20000
80+
even when in other uncommited transaction
81+
many rows are inserted.
82+
Connection 1
83+
COUNT(*)
84+
262144
85+
Rollback the insert
86+
rollback;
87+
Connection default
88+
Test correctly estimates the number of rows as 1
89+
after rollback.
90+
DROP TABLE t1,t2;
Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1 @@
1+
--innodb_stats_include_delete_marked=on
Lines changed: 121 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,121 @@
1+
--echo #
2+
--echo # Bug 23333990 PERSISTENT INDEX STATISTICS UPDATE BEFORE
3+
--echo # TRANSACTION IS COMMITTED
4+
--echo #
5+
6+
--source include/big_test.inc
7+
--echo "Test 1:- Uncommited delete test"
8+
CREATE TABLE t1 (id INT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY,
9+
val INT UNSIGNED NOT NULL,
10+
INDEX (val)) ENGINE=INNODB
11+
STATS_PERSISTENT=1,STATS_AUTO_RECALC=1;
12+
13+
14+
INSERT INTO t1 (val) VALUES (CEIL(RAND()*20));
15+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
16+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
17+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
18+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
19+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
20+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
21+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
22+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
23+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
24+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
25+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
26+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
27+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
28+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
29+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
30+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
31+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
32+
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
33+
34+
SELECT COUNT(*) FROM t1;
35+
ANALYZE TABLE t1;
36+
37+
connect(con1, localhost, root,,);
38+
39+
--echo Connection 1
40+
connection con1;
41+
START TRANSACTION;
42+
DELETE FROM t1;
43+
send SELECT COUNT(*) FROM t1;
44+
45+
--echo Connection Default
46+
connection default;
47+
let $row_count= query_get_value(EXPLAIN SELECT * FROM t1 WHERE val=4, rows,1);
48+
if ($row_count > 20000)
49+
{
50+
--echo Test correctly estimates the number of rows as > 20000
51+
--echo even when in other uncommmited transaction
52+
--echo all rows have been deleted.
53+
}
54+
55+
--echo Connection 1
56+
connection con1;
57+
reap;
58+
commit;
59+
60+
--echo Connection deafult
61+
connection default;
62+
63+
--echo Test 2:- Insert and rollback test
64+
CREATE TABLE t2 (id INT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY,
65+
val INT UNSIGNED NOT NULL,
66+
INDEX (val)) ENGINE=INNODB
67+
STATS_PERSISTENT=1,STATS_AUTO_RECALC=1;
68+
69+
--echo Connection 1
70+
connection con1;
71+
72+
START TRANSACTION;
73+
INSERT INTO t2 (val) VALUES (CEIL(RAND()*20));
74+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
75+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
76+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
77+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
78+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
79+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
80+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
81+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
82+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
83+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
84+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
85+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
86+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
87+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
88+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
89+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
90+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
91+
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
92+
send SELECT COUNT(*) FROM t2;
93+
94+
--echo Connection default
95+
connection default;
96+
select count(*) from t2;
97+
let $row_count= query_get_value(EXPLAIN SELECT * FROM t2 WHERE val=4, rows,1);
98+
if ($row_count > 20000)
99+
{
100+
--echo Test correctly estimates the number of rows as > 20000
101+
--echo even when in other uncommited transaction
102+
--echo many rows are inserted.
103+
}
104+
105+
--echo Connection 1
106+
connection con1;
107+
reap;
108+
--echo Rollback the insert
109+
rollback;
110+
111+
--echo Connection default
112+
connection default;
113+
let $row_count= query_get_value(EXPLAIN SELECT * FROM t2 WHERE val=4, rows,1);
114+
if ($row_count <= 1)
115+
{
116+
--echo Test correctly estimates the number of rows as $row_count
117+
--echo after rollback.
118+
}
119+
120+
disconnect con1;
121+
DROP TABLE t1,t2;
Lines changed: 25 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,25 @@
1+
SELECT @@innodb_stats_include_delete_marked;
2+
@@innodb_stats_include_delete_marked
3+
0
4+
SET GLOBAL innodb_stats_include_delete_marked=1;
5+
SELECT @@innodb_stats_include_delete_marked;
6+
@@innodb_stats_include_delete_marked
7+
1
8+
SET SESSION innodb_stats_include_delete_marked=1;
9+
ERROR HY000: Variable 'innodb_stats_include_delete_marked' is a GLOBAL variable and should be set with SET GLOBAL
10+
SET GLOBAL innodb_stats_include_delete_marked=100;
11+
ERROR 42000: Variable 'innodb_stats_include_delete_marked' can't be set to the value of '100'
12+
SET GLOBAL innodb_stats_include_delete_marked=foo;
13+
ERROR 42000: Variable 'innodb_stats_include_delete_marked' can't be set to the value of 'foo'
14+
SET GLOBAL innodb_stats_include_delete_marked=OFF ;
15+
SELECT @@innodb_stats_include_delete_marked;
16+
@@innodb_stats_include_delete_marked
17+
0
18+
SET GLOBAL innodb_stats_include_delete_marked=ON ;
19+
SELECT @@innodb_stats_include_delete_marked;
20+
@@innodb_stats_include_delete_marked
21+
1
22+
SET GLOBAL innodb_stats_include_delete_marked=Default ;
23+
SELECT @@innodb_stats_include_delete_marked;
24+
@@innodb_stats_include_delete_marked
25+
0
Lines changed: 53 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,53 @@
1+
###############################################################################
2+
# #
3+
# Variable Name: innodb_stats_include_delete_marked #
4+
# Scope: Global #
5+
# Access Type: Dynamic #
6+
# Data Type: numeric #
7+
# #
8+
# #
9+
# Creation Date: 2016-08-29 #
10+
# Author : Aditya #
11+
# #
12+
# #
13+
# Description: #
14+
# * Value check #
15+
# * Scope check #
16+
# #
17+
###############################################################################
18+
19+
--source include/have_innodb.inc
20+
21+
####################################################################
22+
# Display default value #
23+
####################################################################
24+
SELECT @@innodb_stats_include_delete_marked;
25+
26+
SET GLOBAL innodb_stats_include_delete_marked=1;
27+
28+
SELECT @@innodb_stats_include_delete_marked;
29+
30+
# check error
31+
--error ER_GLOBAL_VARIABLE
32+
SET SESSION innodb_stats_include_delete_marked=1;
33+
34+
# check error
35+
--error ER_WRONG_VALUE_FOR_VAR
36+
SET GLOBAL innodb_stats_include_delete_marked=100;
37+
38+
# check error
39+
--error ER_WRONG_VALUE_FOR_VAR
40+
SET GLOBAL innodb_stats_include_delete_marked=foo;
41+
42+
SET GLOBAL innodb_stats_include_delete_marked=OFF ;
43+
44+
SELECT @@innodb_stats_include_delete_marked;
45+
46+
SET GLOBAL innodb_stats_include_delete_marked=ON ;
47+
48+
SELECT @@innodb_stats_include_delete_marked;
49+
50+
# Check with default setting
51+
SET GLOBAL innodb_stats_include_delete_marked=Default ;
52+
53+
SELECT @@innodb_stats_include_delete_marked;

storage/innobase/dict/dict0stats.cc

Lines changed: 10 additions & 3 deletions
Original file line numberDiff line numberDiff line change
@@ -1,6 +1,6 @@
11
/*****************************************************************************
22
3-
Copyright (c) 2009, 2015, Oracle and/or its affiliates. All Rights Reserved.
3+
Copyright (c) 2009, 2016, Oracle and/or its affiliates. All Rights Reserved.
44
55
This program is free software; you can redistribute it and/or modify it under
66
the terms of the GNU General Public License as published by the Free Software
@@ -1095,7 +1095,8 @@ dict_stats_analyze_index_level(
10951095
them away) which brings non-determinism. We skip only
10961096
leaf-level delete marks because delete marks on
10971097
non-leaf level do not make sense. */
1098-
if (level == 0 &&
1098+
1099+
if (level == 0 && srv_stats_include_delete_marked? 0:
10991100
rec_get_deleted_flag(
11001101
rec,
11011102
page_is_comp(btr_pcur_get_page(&pcur)))) {
@@ -1281,8 +1282,12 @@ enum page_scan_method_t {
12811282
the given page and count the number of
12821283
distinct ones, also ignore delete marked
12831284
records */
1284-
QUIT_ON_FIRST_NON_BORING/* quit when the first record that differs
1285+
QUIT_ON_FIRST_NON_BORING,/* quit when the first record that differs
12851286
from its right neighbor is found */
1287+
COUNT_ALL_NON_BORING_INCLUDE_DEL_MARKED/* scan all records on
1288+
the given page and count the number of
1289+
distinct ones, include delete marked
1290+
records */
12861291
};
12871292
/* @} */
12881293

@@ -1558,6 +1563,8 @@ dict_stats_analyze_index_below_cur(
15581563

15591564
offsets_rec = dict_stats_scan_page(
15601565
&rec, offsets1, offsets2, index, page, n_prefix,
1566+
srv_stats_include_delete_marked ?
1567+
COUNT_ALL_NON_BORING_INCLUDE_DEL_MARKED:
15611568
COUNT_ALL_NON_BORING_AND_SKIP_DEL_MARKED, n_diff,
15621569
n_external_pages);
15631570

storage/innobase/handler/ha_innodb.cc

Lines changed: 7 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -15911,6 +15911,12 @@ static MYSQL_SYSVAR_BOOL(doublewrite, innobase_use_doublewrite,
1591115911
"Disable with --skip-innodb-doublewrite.",
1591215912
NULL, NULL, TRUE);
1591315913

15914+
static MYSQL_SYSVAR_BOOL(stats_include_delete_marked,
15915+
srv_stats_include_delete_marked,
15916+
PLUGIN_VAR_OPCMDARG,
15917+
"Scan delete marked records for persistent stat",
15918+
NULL, NULL, FALSE);
15919+
1591415920
static MYSQL_SYSVAR_ULONG(io_capacity, srv_io_capacity,
1591515921
PLUGIN_VAR_RQCMDARG,
1591615922
"Number of IOPs the server can do. Tunes the background IO rate",
@@ -16712,6 +16718,7 @@ static struct st_mysql_sys_var* innobase_system_variables[]= {
1671216718
MYSQL_SYSVAR(data_file_path),
1671316719
MYSQL_SYSVAR(data_home_dir),
1671416720
MYSQL_SYSVAR(doublewrite),
16721+
MYSQL_SYSVAR(stats_include_delete_marked),
1671516722
MYSQL_SYSVAR(api_enable_binlog),
1671616723
MYSQL_SYSVAR(api_enable_mdl),
1671716724
MYSQL_SYSVAR(api_disable_rowlock),

storage/innobase/include/srv0srv.h

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -347,6 +347,7 @@ extern unsigned long long srv_stats_transient_sample_pages;
347347
extern my_bool srv_stats_persistent;
348348
extern unsigned long long srv_stats_persistent_sample_pages;
349349
extern my_bool srv_stats_auto_recalc;
350+
extern my_bool srv_stats_include_delete_marked;
350351

351352
extern ibool srv_use_doublewrite_buf;
352353
extern ulong srv_doublewrite_batch_size;

storage/innobase/srv/srv0srv.cc

Lines changed: 1 addition & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -340,6 +340,7 @@ this many index pages, there are 2 ways to calculate statistics:
340340
table/index are not found in the innodb database */
341341
UNIV_INTERN unsigned long long srv_stats_transient_sample_pages = 8;
342342
UNIV_INTERN my_bool srv_stats_persistent = TRUE;
343+
UNIV_INTERN my_bool srv_stats_include_delete_marked = FALSE;
343344
UNIV_INTERN unsigned long long srv_stats_persistent_sample_pages = 20;
344345
UNIV_INTERN my_bool srv_stats_auto_recalc = TRUE;
345346

0 commit comments

Comments
 (0)