Skip to content

Commit

Permalink
Changing all cost calculation to be given in milliseconds
Browse files Browse the repository at this point in the history
This makes it easier to compare different costs and also allows
the optimizer to optimizer different storage engines more reliably.

- Added tests/check_costs.pl, a tool to verify optimizer cost calculations.
  - Most engine costs has been found with this program. All steps to
    calculate the new costs are documented in Docs/optimizer_costs.txt

- User optimizer_cost variables are given in microseconds (as individual
  costs can be very small). Internally they are stored in ms.
- Changed DISK_READ_COST (was DISK_SEEK_BASE_COST) from a hard disk cost
  (9 ms) to common SSD cost (400MB/sec).
- Removed cost calculations for hard disks (rotation etc).
- Changed the following handler functions to return IO_AND_CPU_COST.
  This makes it easy to apply different cost modifiers in ha_..time()
  functions for io and cpu costs.
  - scan_time()
  - rnd_pos_time() & rnd_pos_call_time()
  - keyread_time()
- Enhanched keyread_time() to calculate the full cost of reading of a set
  of keys with a given number of ranges and optional number of blocks that
  need to be accessed.
- Removed read_time() as keyread_time() + rnd_pos_time() can do the same
  thing and more.
- Tuned cost for: heap, myisam, Aria, InnoDB, archive and MyRocks.
  Used heap table costs for json_table. The rest are using default engine
  costs.
- Added the following new optimizer variables:
  - optimizer_disk_read_ratio
  - optimizer_disk_read_cost
  - optimizer_key_lookup_cost
  - optimizer_row_lookup_cost
  - optimizer_row_next_find_cost
  - optimizer_scan_cost
- Moved all engine specific cost to OPTIMIZER_COSTS structure.
- Changed costs to use 'records_out' instead of 'records_read' when
  recalculating costs.
- Split optimizer_costs.h to optimizer_costs.h and optimizer_defaults.h.
  This allows one to change costs without having to compile a lot of
  files.
- Updated costs for filter lookup.
- Use a better cost estimate in best_extension_by_limited_search()
  for the sorting cost.
- Fixed previous issues with 'filtered' explain column as we are now
  using 'records_out' (min rows seen for table) to calculate filtering.
  This greatly simplifies the filtering code in
  JOIN_TAB::save_explain_data().

This change caused a lot of queries to be optimized differently than
before, which exposed different issues in the optimizer that needs to
be fixed.  These fixes are in the following commits.  To not have to
change the same test case over and over again, the changes in the test
cases are done in a single commit after all the critical change sets
are done.

InnoDB changes:
- Updated InnoDB to not divide big range cost with 2.
- Added cost for InnoDB (innobase_update_optimizer_costs()).
- Don't mark clustered primary key with HA_KEYREAD_ONLY. This will
  prevent that the optimizer is trying to use index-only scans on
  the clustered key.
- Disabled ha_innobase::scan_time() and ha_innobase::read_time() and
  ha_innobase::rnd_pos_time() as the default engine cost functions now
  works good for InnoDB.

Other things:
- Added  --show-query-costs (\Q) option to mysql.cc to show the query
  cost after each query (good when working with query costs).
- Extended my_getopt with GET_ADJUSTED_VALUE which allows one to adjust
  the value that user is given. This is used to change cost from
  microseconds (user input) to milliseconds (what the server is
  internally using).
- Added include/my_tracker.h  ; Useful include file to quickly test
  costs of a function.
- Use handler::set_table() in all places instead of 'table= arg'.
- Added SHOW_OPTIMIZER_COSTS to sys variables. These are input and
  shown in microseconds for the user but stored as milliseconds.
  This is to make the numbers easier to read for the user (less
  pre-zeros).  Implemented in 'Sys_var_optimizer_cost' class.
- In test_quick_select() do not use index scans if 'no_keyread' is set
  for the table. This is what we do in other places of the server.
- Added THD parameter to Unique::get_use_cost() and
  check_index_intersect_extension() and similar functions to be able
  to provide costs to called functions.
- Changed 'records' to 'rows' in optimizer_trace.
- Write more information to optimizer_trace.
- Added INDEX_BLOCK_FILL_FACTOR_MUL (4) and INDEX_BLOCK_FILL_FACTOR_DIV (3)
  to calculate usage space of keys in b-trees. (Before we used numeric
  constants).
- Removed code that assumed that b-trees has similar costs as binary
  trees. Replaced with engine calls that returns the cost.
- Added Bitmap::find_first_bit()
- Added timings to join_cache for ANALYZE table (patch by Sergei Petrunia).
- Added records_init and records_after_filter to POSITION to remember
  more of what best_access_patch() calculates.
- table_after_join_selectivity() changed to recalculate 'records_out'
  based on the new fields from best_access_patch()

Bug fixes:
- Some queries did not update last_query_cost (was 0). Fixed by moving
  setting thd->...last_query_cost in JOIN::optimize().
- Write '0' as number of rows for const tables with a matching row.

Some internals:
- Engine cost are stored in OPTIMIZER_COSTS structure.  When a
  handlerton is created, we also created a new cost variable for the
  handlerton. We also create a new variable if the user changes a
  optimizer cost for a not yet loaded handlerton either with command
  line arguments or with SET
  @@global.engine.optimizer_cost_variable=xx.
- There are 3 global OPTIMIZER_COSTS variables:
  default_optimizer_costs   The default costs + changes from the
                            command line without an engine specifier.
  heap_optimizer_costs      Heap table costs, used for temporary tables
  tmp_table_optimizer_costs The cost for the default on disk internal
                            temporary table (MyISAM or Aria)
- The engine cost for a table is stored in table_share. To speed up
  accesses the handler has a pointer to this. The cost is copied
  to the table on first access. If one wants to change the cost one
  must first update the global engine cost and then do a FLUSH TABLES.
  This was done to be able to access the costs for an open table
  without any locks.
- When a handlerton is created, the cost are updated the following way:
  See sql/keycaches.cc for details:
  - Use 'default_optimizer_costs' as a base
  - Call hton->update_optimizer_costs() to override with the engines
    default costs.
  - Override the costs that the user has specified for the engine.
  - One handler open, copy the engine cost from handlerton to TABLE_SHARE.
  - Call handler::update_optimizer_costs() to allow the engine to update
    cost for this particular table.
  - There are two costs stored in THD. These are copied to the handler
    when the table is used in a query:
    - optimizer_where_cost
    - optimizer_scan_setup_cost
- Simply code in best_access_path() by storing all cost result in a
  structure. (Idea/Suggestion by Igor)
  • Loading branch information
montywi authored and spetrunia committed Feb 2, 2023
1 parent 590416e commit b66cdbd
Show file tree
Hide file tree
Showing 110 changed files with 5,362 additions and 1,526 deletions.
1,309 changes: 1,309 additions & 0 deletions Docs/optimizer_costs.txt

Large diffs are not rendered by default.

58 changes: 52 additions & 6 deletions client/mysql.cc
Original file line number Diff line number Diff line change
Expand Up @@ -46,7 +46,7 @@
#include <locale.h>
#endif

const char *VER= "15.1";
const char *VER= "15.2";

/* Don't try to make a nice table if the data is too big */
#define MAX_COLUMN_LENGTH 1024
Expand Down Expand Up @@ -246,7 +246,7 @@ static my_bool ignore_errors=0,wait_flag=0,quick=0,
tty_password= 0, opt_nobeep=0, opt_reconnect=1,
opt_secure_auth= 0,
default_pager_set= 0, opt_sigint_ignore= 0,
auto_vertical_output= 0,
auto_vertical_output= 0, show_query_cost= 0,
show_warnings= 0, executing_query= 0,
ignore_spaces= 0, opt_binhex= 0, opt_progress_reports;
static my_bool debug_info_flag, debug_check_flag, batch_abort_on_error;
Expand Down Expand Up @@ -324,6 +324,7 @@ static int com_quit(String *str,char*),
com_notee(String *str, char*), com_charset(String *str,char*),
com_prompt(String *str, char*), com_delimiter(String *str, char*),
com_warnings(String *str, char*), com_nowarnings(String *str, char*);
static int com_query_cost(String *str, char*);

#ifdef USE_POPEN
static int com_nopager(String *str, char*), com_pager(String *str, char*),
Expand Down Expand Up @@ -395,6 +396,8 @@ static COMMANDS commands[] = {
{ "print", 'p', com_print, 0, "Print current command." },
{ "prompt", 'R', com_prompt, 1, "Change your mysql prompt."},
{ "quit", 'q', com_quit, 0, "Quit mysql." },
{ "costs", 'Q', com_query_cost, 0,
"Toggle showing query costs after each query" },
{ "rehash", '#', com_rehash, 0, "Rebuild completion hash." },
{ "source", '.', com_source, 1,
"Execute an SQL script file. Takes a file name as an argument."},
Expand Down Expand Up @@ -1156,6 +1159,7 @@ static void print_table_data_xml(MYSQL_RES *result);
static void print_tab_data(MYSQL_RES *result);
static void print_table_data_vertically(MYSQL_RES *result);
static void print_warnings(void);
static void print_last_query_cost(void);
static void end_timer(ulonglong start_time, char *buff);
static void nice_time(double sec,char *buff,bool part_second);
extern "C" sig_handler mysql_end(int sig) __attribute__ ((noreturn));
Expand Down Expand Up @@ -1828,6 +1832,10 @@ static struct my_option my_long_options[] =
{"show-warnings", OPT_SHOW_WARNINGS, "Show warnings after every statement.",
&show_warnings, &show_warnings, 0, GET_BOOL, NO_ARG,
0, 0, 0, 0, 0, 0},
{"show-query-costs", OPT_SHOW_WARNINGS,
"Show query cost after every statement.",
&show_query_cost, &show_query_cost, 0, GET_BOOL, NO_ARG,
0, 0, 0, 0, 0, 0},
{"plugin_dir", OPT_PLUGIN_DIR, "Directory for client-side plugins.",
&opt_plugin_dir, &opt_plugin_dir, 0,
GET_STR, REQUIRED_ARG, 0, 0, 0, 0, 0, 0},
Expand Down Expand Up @@ -3586,6 +3594,8 @@ com_go(String *buffer,char *line __attribute__((unused)))
/* Show warnings if any or error occurred */
if (show_warnings == 1 && (warnings >= 1 || error))
print_warnings();
if (show_query_cost)
print_last_query_cost();

if (!error && !status.batch &&
(mysql.server_status & SERVER_STATUS_DB_DROPPED))
Expand Down Expand Up @@ -4190,6 +4200,30 @@ static void print_warnings()
}


/* print_last_query_cost */

static void print_last_query_cost()
{
const char *query;
char *end;
MYSQL_RES *result;
MYSQL_ROW cur;

query= "show status like 'last_query_cost'";
mysql_real_query_for_lazy(query, strlen(query));
mysql_store_result_for_lazy(&result);
if (!result)
goto end;

cur= mysql_fetch_row(result);
if (strtod(cur[1], &end) != 0.0)
tee_fprintf(PAGER, "%s: %s\n\n", cur[0], cur[1]);

end:
mysql_free_result(result);
}


static const char *array_value(const char **array, char key)
{
for (; *array; array+= 2)
Expand Down Expand Up @@ -4765,6 +4799,18 @@ com_nowarnings(String *buffer __attribute__((unused)),
return 0;
}

static int
com_query_cost(String *buffer __attribute__((unused)),
char *line __attribute__((unused)))
{
show_query_cost= 1 - show_query_cost;
if (show_query_cost)
put_info("Last_query_cost enabled.",INFO_INFO);
else
put_info("Last_query_cost disabled.",INFO_INFO);
return 0;
}

/*
Gets argument from a command on the command line. If mode is not GET_NEXT,
skips the command and returns the first argument. The line is modified by
Expand Down Expand Up @@ -5020,17 +5066,17 @@ com_status(String *buffer __attribute__((unused)),
ulonglong id;
MYSQL_RES *UNINIT_VAR(result);

/*
Don't remove "limit 1",
it is protection against SQL_SELECT_LIMIT=0
*/
if (mysql_real_query_for_lazy(
C_STRING_WITH_LEN("select DATABASE(), USER() limit 1")))
return 0;

tee_puts("--------------", stdout);
usage(1); /* Print version */
tee_fprintf(stdout, "\nConnection id:\t\t%lu\n",mysql_thread_id(&mysql));
/*
Don't remove "limit 1",
it is protection against SQL_SELECT_LIMIT=0
*/
if (!mysql_store_result_for_lazy(&result))
{
MYSQL_ROW cur=mysql_fetch_row(result);
Expand Down
3 changes: 3 additions & 0 deletions include/my_getopt.h
Original file line number Diff line number Diff line change
Expand Up @@ -40,6 +40,7 @@ C_MODE_START
#define GET_FLAGSET 15
#define GET_BIT 16

#define GET_ADJUST_VALUE 256
#define GET_ASK_ADDR 128
#define GET_AUTO 64
#define GET_TYPE_MASK 63
Expand Down Expand Up @@ -100,6 +101,7 @@ typedef my_bool (*my_get_one_option)(const struct my_option *, const char *, con
typedef void *(*my_getopt_value)(const char *, uint, const struct my_option *,
int *);

typedef void (*my_getopt_adjust)(const struct my_option *, void *);

extern char *disabled_my_option;
extern char *autoset_my_option;
Expand All @@ -109,6 +111,7 @@ extern my_bool my_getopt_prefix_matching;
extern my_bool my_handle_options_init_variables;
extern my_error_reporter my_getopt_error_reporter;
extern my_getopt_value my_getopt_get_addr;
extern my_getopt_adjust my_getopt_adjust_value;

extern int handle_options (int *argc, char ***argv,
const struct my_option *longopts, my_get_one_option)
Expand Down
1 change: 1 addition & 0 deletions include/my_global.h
Original file line number Diff line number Diff line change
Expand Up @@ -682,6 +682,7 @@ typedef SOCKET_SIZE_TYPE size_socket;
Io buffer size; Must be a power of 2 and a multiple of 512. May be
smaller what the disk page size. This influences the speed of the
isam btree library. eg to big to slow.
4096 is a common block size on SSDs.
*/
#define IO_SIZE 4096U
/*
Expand Down
41 changes: 41 additions & 0 deletions include/my_tracker.h
Original file line number Diff line number Diff line change
@@ -0,0 +1,41 @@
/* Copyright (c) 2022, MariaDB Corporation.
This program is free software; you can redistribute it and/or modify
it under the terms of the GNU General Public License as published by
the Free Software Foundation; version 2 of the License.
This program is distributed in the hope that it will be useful,
but WITHOUT ANY WARRANTY; without even the implied warranty of
MERCHANTABILITY or FITNESS FOR A PARTICULAR PURPOSE. See the
GNU General Public License for more details.
You should have received a copy of the GNU General Public License
along with this program; if not, write to the Free Software
Foundation, Inc., 51 Franklin St, Fifth Floor, Boston, MA 02110-1335 USA */

/*
Trivial framework to add a tracker to a C function
*/

#include "my_rdtsc.h"

struct my_time_tracker
{
ulonglong counter;
ulonglong cycles;
};

#ifdef HAVE_TIME_TRACKING
#define START_TRACKING ulonglong my_start_time= my_timer_cycles()
#define END_TRACKING(var) \
{ \
ulonglong my_end_time= my_timer_cycles(); \
(var)->counter++; \
(var)->cycles+= (unlikely(my_end_time < my_start_time) ? \
my_end_time - my_start_time + ULONGLONG_MAX : \
my_end_time - my_start_time); \
}
#else
#define START_TRACKING
#define END_TRACKING(var) do { } while(0)
#endif
2 changes: 2 additions & 0 deletions include/myisam.h
Original file line number Diff line number Diff line change
Expand Up @@ -435,6 +435,8 @@ int thr_write_keys(MI_SORT_PARAM *sort_param);
int sort_write_record(MI_SORT_PARAM *sort_param);
int _create_index_by_sort(MI_SORT_PARAM *info,my_bool no_messages, ulonglong);
my_bool mi_too_big_key_for_sort(MI_KEYDEF *key, ha_rows rows);
struct OPTIMIZER_COSTS;
void myisam_update_optimizer_costs(struct OPTIMIZER_COSTS *costs);

#ifdef __cplusplus
}
Expand Down
2 changes: 1 addition & 1 deletion mysql-test/include/analyze-format.inc
Original file line number Diff line number Diff line change
@@ -1,3 +1,3 @@
# The time on ANALYSE FORMAT=JSON is rather variable

--replace_regex /("(r_total_time_ms|r_table_time_ms|r_other_time_ms|r_buffer_size|r_filling_time_ms|r_query_time_in_progress_ms)": )[^, \n]*/\1"REPLACED"/
--replace_regex /("(r_total_time_ms|r_table_time_ms|r_other_time_ms|r_buffer_size|r_filling_time_ms|r_query_time_in_progress_ms|r_unpack_time_ms)": )[^, \n]*/\1"REPLACED"/
26 changes: 16 additions & 10 deletions mysql-test/main/analyze_format_json.result
Original file line number Diff line number Diff line change
Expand Up @@ -183,7 +183,8 @@ ANALYZE
"buffer_type": "flat",
"buffer_size": "1Kb",
"join_type": "BNL",
"r_filtered": 100
"r_filtered": 100,
"r_unpack_time_ms": "REPLACED"
}
}
]
Expand Down Expand Up @@ -233,7 +234,8 @@ ANALYZE
"buffer_size": "1Kb",
"join_type": "BNL",
"attached_condition": "tbl1.c > tbl2.c",
"r_filtered": 15.83333333
"r_filtered": 15.83333333,
"r_unpack_time_ms": "REPLACED"
}
}
]
Expand Down Expand Up @@ -769,34 +771,36 @@ ANALYZE
"r_other_time_ms": "REPLACED",
"filtered": 100,
"r_filtered": 0,
"attached_condition": "<in_optimizer>(t2.b,t2.b in (subquery#2))"
"attached_condition": "<in_optimizer>(t2.b,<exists>(subquery#2))"
},
"buffer_type": "flat",
"buffer_size": "65",
"join_type": "BNL",
"attached_condition": "<in_optimizer>(t2.b,t2.b in (subquery#2))",
"r_filtered": null
"attached_condition": "<in_optimizer>(t2.b,<exists>(subquery#2))",
"r_filtered": null,
"r_unpack_time_ms": "REPLACED"
}
}
],
"subqueries": [
{
"query_block": {
"select_id": 2,
"r_loops": 1,
"r_loops": 2,
"r_total_time_ms": "REPLACED",
"nested_loop": [
{
"table": {
"table_name": "t1",
"access_type": "ALL",
"r_loops": 1,
"r_loops": 2,
"rows": 2,
"r_rows": 2,
"r_table_time_ms": "REPLACED",
"r_other_time_ms": "REPLACED",
"filtered": 100,
"r_filtered": 100
"r_filtered": 0,
"attached_condition": "4 = t1.a"
}
}
]
Expand Down Expand Up @@ -878,7 +882,8 @@ ANALYZE
"buffer_type": "flat",
"buffer_size": "1",
"join_type": "BNL",
"r_filtered": null
"r_filtered": null,
"r_unpack_time_ms": "REPLACED"
}
}
],
Expand Down Expand Up @@ -916,7 +921,8 @@ ANALYZE
"buffer_size": "65",
"join_type": "BNL",
"attached_condition": "t2.f2 = t3.f3",
"r_filtered": null
"r_filtered": null,
"r_unpack_time_ms": "REPLACED"
}
}
]
Expand Down
6 changes: 4 additions & 2 deletions mysql-test/main/analyze_stmt_orderby.result
Original file line number Diff line number Diff line change
Expand Up @@ -494,7 +494,8 @@ ANALYZE
"buffer_size": "65",
"join_type": "BNL",
"attached_condition": "t3.a = t0.a",
"r_filtered": 10
"r_filtered": 10,
"r_unpack_time_ms": "REPLACED"
}
}
]
Expand Down Expand Up @@ -578,7 +579,8 @@ ANALYZE
"buffer_size": "119",
"join_type": "BNL",
"attached_condition": "t5.a = t6.a",
"r_filtered": 21.42857143
"r_filtered": 21.42857143,
"r_unpack_time_ms": "REPLACED"
}
}
]
Expand Down
2 changes: 1 addition & 1 deletion mysql-test/main/ctype_collate.result
Original file line number Diff line number Diff line change
Expand Up @@ -748,7 +748,7 @@ hex(b)
explain
select hex(b) from t1 where b<'zzz' order by b;
id select_type table type possible_keys key key_len ref rows Extra
1 SIMPLE t1 ALL PRIMARY NULL NULL NULL 4 Using where; Using filesort
1 SIMPLE t1 range PRIMARY PRIMARY 34 NULL 4 Using where; Using filesort
select hex(b) from t1 where b<'zzz' order by b;
hex(b)
00
Expand Down
1 change: 0 additions & 1 deletion mysql-test/main/delete.result
Original file line number Diff line number Diff line change
Expand Up @@ -128,7 +128,6 @@ a b
delete ignore t11.*, t12.* from t11,t12 where t11.a = t12.a and t11.b <> (select b from t2 where t11.a < t2.a);
Warnings:
Warning 1242 Subquery returns more than 1 row
Warning 1242 Subquery returns more than 1 row
select * from t11;
a b
0 10
Expand Down
12 changes: 8 additions & 4 deletions mysql-test/main/except.result
Original file line number Diff line number Diff line change
Expand Up @@ -387,7 +387,8 @@ ANALYZE
"buffer_type": "flat",
"buffer_size": "119",
"join_type": "BNL",
"r_filtered": 100
"r_filtered": 100,
"r_unpack_time_ms": "REPLACED"
}
}
]
Expand Down Expand Up @@ -429,7 +430,8 @@ ANALYZE
"buffer_type": "flat",
"buffer_size": "119",
"join_type": "BNL",
"r_filtered": 100
"r_filtered": 100,
"r_unpack_time_ms": "REPLACED"
}
}
]
Expand Down Expand Up @@ -505,7 +507,8 @@ ANALYZE
"buffer_type": "flat",
"buffer_size": "119",
"join_type": "BNL",
"r_filtered": 100
"r_filtered": 100,
"r_unpack_time_ms": "REPLACED"
}
}
]
Expand Down Expand Up @@ -547,7 +550,8 @@ ANALYZE
"buffer_type": "flat",
"buffer_size": "119",
"join_type": "BNL",
"r_filtered": 100
"r_filtered": 100,
"r_unpack_time_ms": "REPLACED"
}
}
]
Expand Down

0 comments on commit b66cdbd

Please sign in to comment.