Commit 44b1fb36 authored by Aditya A's avatar Aditya A Committed by Marko Mäkelä

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 .
parent 6f5f7208
#
# Bug 23333990 PERSISTENT INDEX STATISTICS UPDATE BEFORE
# TRANSACTION IS COMMITTED
#
"Test 1:- Uncommited delete test"
CREATE TABLE t1 (id INT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY,
val INT UNSIGNED NOT NULL,
INDEX (val)) ENGINE=INNODB
STATS_PERSISTENT=1,STATS_AUTO_RECALC=1;
INSERT INTO t1 (val) VALUES (CEIL(RAND()*20));
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
SELECT COUNT(*) FROM t1;
COUNT(*)
262144
ANALYZE TABLE t1;
Table Op Msg_type Msg_text
test.t1 analyze status OK
connect con1, localhost, root,,;
START TRANSACTION;
DELETE FROM t1;
SELECT COUNT(*) FROM t1;
connection default;
Test correctly estimates the number of rows as > 20000
even when in other uncommmited transaction
all rows have been deleted.
connection con1;
COUNT(*)
0
commit;
connection default;
Test 2:- Insert and rollback test
CREATE TABLE t2 (id INT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY,
val INT UNSIGNED NOT NULL,
INDEX (val)) ENGINE=INNODB
STATS_PERSISTENT=1,STATS_AUTO_RECALC=1;
connection con1;
START TRANSACTION;
INSERT INTO t2 (val) VALUES (CEIL(RAND()*20));
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
SELECT COUNT(*) FROM t2;
connection default;
select count(*) from t2;
count(*)
0
Test correctly estimates the number of rows as > 20000
even when in other uncommited transaction
many rows are inserted.
connection con1;
COUNT(*)
262144
Rollback the insert
rollback;
disconnect con1;
connection default;
Test correctly estimates the number of rows as 1
after rollback.
DROP TABLE t1,t2;
--source include/have_innodb.inc
--source include/big_test.inc
--echo #
--echo # Bug 23333990 PERSISTENT INDEX STATISTICS UPDATE BEFORE
--echo # TRANSACTION IS COMMITTED
--echo #
--echo "Test 1:- Uncommited delete test"
CREATE TABLE t1 (id INT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY,
val INT UNSIGNED NOT NULL,
INDEX (val)) ENGINE=INNODB
STATS_PERSISTENT=1,STATS_AUTO_RECALC=1;
INSERT INTO t1 (val) VALUES (CEIL(RAND()*20));
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
INSERT INTO t1 (val) SELECT CEIL(RAND()*20) FROM t1;
SELECT COUNT(*) FROM t1;
ANALYZE TABLE t1;
connect(con1, localhost, root,,);
START TRANSACTION;
DELETE FROM t1;
send SELECT COUNT(*) FROM t1;
connection default;
let $row_count= query_get_value(EXPLAIN SELECT * FROM t1 WHERE val=4, rows,1);
if ($row_count > 20000)
{
--echo Test correctly estimates the number of rows as > 20000
--echo even when in other uncommmited transaction
--echo all rows have been deleted.
}
connection con1;
reap;
commit;
connection default;
--echo Test 2:- Insert and rollback test
CREATE TABLE t2 (id INT UNSIGNED NOT NULL AUTO_INCREMENT PRIMARY KEY,
val INT UNSIGNED NOT NULL,
INDEX (val)) ENGINE=INNODB
STATS_PERSISTENT=1,STATS_AUTO_RECALC=1;
connection con1;
START TRANSACTION;
INSERT INTO t2 (val) VALUES (CEIL(RAND()*20));
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
INSERT INTO t2 (val) SELECT CEIL(RAND()*20) FROM t2;
send SELECT COUNT(*) FROM t2;
connection default;
select count(*) from t2;
let $row_count= query_get_value(EXPLAIN SELECT * FROM t2 WHERE val=4, rows,1);
if ($row_count > 20000)
{
--echo Test correctly estimates the number of rows as > 20000
--echo even when in other uncommited transaction
--echo many rows are inserted.
}
connection con1;
reap;
--echo Rollback the insert
rollback;
disconnect con1;
connection default;
let $row_count= query_get_value(EXPLAIN SELECT * FROM t2 WHERE val=4, rows,1);
if ($row_count <= 1)
{
--echo Test correctly estimates the number of rows as $row_count
--echo after rollback.
}
DROP TABLE t1,t2;
......@@ -1152,7 +1152,8 @@ dict_stats_analyze_index_level(
them away) which brings non-determinism. We skip only
leaf-level delete marks because delete marks on
non-leaf level do not make sense. */
if (level == 0 &&
if (level == 0 && srv_stats_include_delete_marked ? 0:
rec_get_deleted_flag(
rec,
page_is_comp(btr_pcur_get_page(&pcur)))) {
......@@ -1176,7 +1177,6 @@ dict_stats_analyze_index_level(
continue;
}
rec_offsets = rec_get_offsets(
rec, index, rec_offsets, n_uniq, &heap);
......@@ -1334,8 +1334,12 @@ enum page_scan_method_t {
the given page and count the number of
distinct ones, also ignore delete marked
records */
QUIT_ON_FIRST_NON_BORING/* quit when the first record that differs
QUIT_ON_FIRST_NON_BORING,/* quit when the first record that differs
from its right neighbor is found */
COUNT_ALL_NON_BORING_INCLUDE_DEL_MARKED/* scan all records on
the given page and count the number of
distinct ones, include delete marked
records */
};
/* @} */
......@@ -1608,6 +1612,8 @@ dict_stats_analyze_index_below_cur(
offsets_rec = dict_stats_scan_page(
&rec, offsets1, offsets2, index, page, n_prefix,
srv_stats_include_delete_marked ?
COUNT_ALL_NON_BORING_INCLUDE_DEL_MARKED:
COUNT_ALL_NON_BORING_AND_SKIP_DEL_MARKED, n_diff,
n_external_pages);
......
......@@ -20769,6 +20769,12 @@ static MYSQL_SYSVAR_BOOL(use_fallocate, innobase_use_fallocate,
"Use posix_fallocate() to allocate files. DEPRECATED, has no effect.",
NULL, NULL, FALSE);
static MYSQL_SYSVAR_BOOL(stats_include_delete_marked,
srv_stats_include_delete_marked,
PLUGIN_VAR_OPCMDARG,
"Include delete marked records when calculating persistent statistics",
NULL, NULL, FALSE);
static MYSQL_SYSVAR_ULONG(io_capacity, srv_io_capacity,
PLUGIN_VAR_RQCMDARG,
"Number of IOPs the server can do. Tunes the background IO rate",
......@@ -21965,6 +21971,7 @@ static struct st_mysql_sys_var* innobase_system_variables[]= {
MYSQL_SYSVAR(temp_data_file_path),
MYSQL_SYSVAR(data_home_dir),
MYSQL_SYSVAR(doublewrite),
MYSQL_SYSVAR(stats_include_delete_marked),
MYSQL_SYSVAR(use_atomic_writes),
MYSQL_SYSVAR(use_fallocate),
MYSQL_SYSVAR(fast_shutdown),
......
......@@ -472,6 +472,7 @@ extern unsigned long long srv_stats_transient_sample_pages;
extern my_bool srv_stats_persistent;
extern unsigned long long srv_stats_persistent_sample_pages;
extern my_bool srv_stats_auto_recalc;
extern my_bool srv_stats_include_delete_marked;
extern unsigned long long srv_stats_modified_counter;
extern my_bool srv_stats_sample_traditional;
......
......@@ -373,6 +373,7 @@ this many index pages, there are 2 ways to calculate statistics:
table/index are not found in the innodb database */
unsigned long long srv_stats_transient_sample_pages = 8;
my_bool srv_stats_persistent = TRUE;
my_bool srv_stats_include_delete_marked = FALSE;
unsigned long long srv_stats_persistent_sample_pages = 20;
my_bool srv_stats_auto_recalc = TRUE;
......
Markdown is supported
0%
or
You are about to add 0 people to the discussion. Proceed with caution.
Finish editing this message first!
Please register or to comment