MDEV-29104 Optimize queries to INFORMATION_SCHEMA.PARAMETERS/ROUTINES
For queries like "SELECT * FROM INFORMATION_SCHEMA.PARAMETERS WHERE SPECIFIC_NAME='proc_name'" and "SELECT * FROM INFORMATION_SCHEMA.ROUTINES WHERE ROUTINE_NAME='proc_name'" there is a possibility to avoid loading of the stored procedure code and parsing it to retrieve parameters. If the name of the procedure/function is specified explicitly then it is possible to filter out routines that do not match at an early stage.
This commit is contained in:
parent
035feae610
commit
d9092e3de7
@ -635,11 +635,11 @@ USE i_s_parameters_test;
|
|||||||
CREATE FUNCTION test_func5 (s CHAR(20)) RETURNS VARCHAR(30)
|
CREATE FUNCTION test_func5 (s CHAR(20)) RETURNS VARCHAR(30)
|
||||||
RETURN CONCAT('XYZ, ' ,s);
|
RETURN CONCAT('XYZ, ' ,s);
|
||||||
#
|
#
|
||||||
# We cannot use the index due to CONCAT()
|
# We cannot use the index due to missing condition on SPECIFIC_SCHEMA,
|
||||||
|
# but we will use SPECIFIC_NAME for filtering records from mysql.proc
|
||||||
FLUSH STATUS;
|
FLUSH STATUS;
|
||||||
SELECT * FROM INFORMATION_SCHEMA.PARAMETERS
|
SELECT * FROM INFORMATION_SCHEMA.PARAMETERS
|
||||||
WHERE CONCAT(SPECIFIC_SCHEMA) = 'i_s_parameters_test'
|
WHERE SPECIFIC_NAME = 'test_func5';
|
||||||
AND SPECIFIC_NAME = 'test_func5';
|
|
||||||
SPECIFIC_CATALOG def
|
SPECIFIC_CATALOG def
|
||||||
SPECIFIC_SCHEMA i_s_parameters_test
|
SPECIFIC_SCHEMA i_s_parameters_test
|
||||||
SPECIFIC_NAME test_func5
|
SPECIFIC_NAME test_func5
|
||||||
@ -675,7 +675,19 @@ ROUTINE_TYPE FUNCTION
|
|||||||
SHOW STATUS LIKE 'handler_read%next';
|
SHOW STATUS LIKE 'handler_read%next';
|
||||||
Variable_name Value
|
Variable_name Value
|
||||||
Handler_read_next 54
|
Handler_read_next 54
|
||||||
Handler_read_rnd_next 97
|
Handler_read_rnd_next 3
|
||||||
|
#
|
||||||
|
# We cannot use the index due to CONCAT(), and filtering by SPECIFIC_NAME
|
||||||
|
# does not work either since SPECIFIC_NAME = 'not_existing_proc'. See
|
||||||
|
# the difference in counters in comparison to the previous test
|
||||||
|
FLUSH STATUS;
|
||||||
|
SELECT * FROM INFORMATION_SCHEMA.PARAMETERS
|
||||||
|
WHERE CONCAT(SPECIFIC_SCHEMA) = 'i_s_parameters_test'
|
||||||
|
AND SPECIFIC_NAME = 'not_existing_proc';
|
||||||
|
SHOW STATUS LIKE 'handler_read%next';
|
||||||
|
Variable_name Value
|
||||||
|
Handler_read_next 54
|
||||||
|
Handler_read_rnd_next 1
|
||||||
#
|
#
|
||||||
# Now the index must be used
|
# Now the index must be used
|
||||||
FLUSH STATUS;
|
FLUSH STATUS;
|
||||||
|
@ -292,11 +292,21 @@ CREATE FUNCTION test_func5 (s CHAR(20)) RETURNS VARCHAR(30)
|
|||||||
RETURN CONCAT('XYZ, ' ,s);
|
RETURN CONCAT('XYZ, ' ,s);
|
||||||
|
|
||||||
--echo #
|
--echo #
|
||||||
--echo # We cannot use the index due to CONCAT()
|
--echo # We cannot use the index due to missing condition on SPECIFIC_SCHEMA,
|
||||||
|
--echo # but we will use SPECIFIC_NAME for filtering records from mysql.proc
|
||||||
|
FLUSH STATUS;
|
||||||
|
query_vertical SELECT * FROM INFORMATION_SCHEMA.PARAMETERS
|
||||||
|
WHERE SPECIFIC_NAME = 'test_func5';
|
||||||
|
SHOW STATUS LIKE 'handler_read%next';
|
||||||
|
|
||||||
|
--echo #
|
||||||
|
--echo # We cannot use the index due to CONCAT(), and filtering by SPECIFIC_NAME
|
||||||
|
--echo # does not work either since SPECIFIC_NAME = 'not_existing_proc'. See
|
||||||
|
--echo # the difference in counters in comparison to the previous test
|
||||||
FLUSH STATUS;
|
FLUSH STATUS;
|
||||||
query_vertical SELECT * FROM INFORMATION_SCHEMA.PARAMETERS
|
query_vertical SELECT * FROM INFORMATION_SCHEMA.PARAMETERS
|
||||||
WHERE CONCAT(SPECIFIC_SCHEMA) = 'i_s_parameters_test'
|
WHERE CONCAT(SPECIFIC_SCHEMA) = 'i_s_parameters_test'
|
||||||
AND SPECIFIC_NAME = 'test_func5';
|
AND SPECIFIC_NAME = 'not_existing_proc';
|
||||||
SHOW STATUS LIKE 'handler_read%next';
|
SHOW STATUS LIKE 'handler_read%next';
|
||||||
|
|
||||||
--echo #
|
--echo #
|
||||||
|
@ -860,11 +860,11 @@ USE i_s_routines_test;
|
|||||||
CREATE FUNCTION test_func5 (s CHAR(20)) RETURNS VARCHAR(30)
|
CREATE FUNCTION test_func5 (s CHAR(20)) RETURNS VARCHAR(30)
|
||||||
RETURN CONCAT('XYZ, ' ,s);
|
RETURN CONCAT('XYZ, ' ,s);
|
||||||
#
|
#
|
||||||
# We cannot use the index due to CONCAT()
|
# We cannot use the index due to missing condition on SPECIFIC_SCHEMA,
|
||||||
|
# but we will use ROUTINE_NAME for filtering records from mysql.proc
|
||||||
FLUSH STATUS;
|
FLUSH STATUS;
|
||||||
SELECT * FROM INFORMATION_SCHEMA.ROUTINES
|
SELECT * FROM INFORMATION_SCHEMA.ROUTINES
|
||||||
WHERE CONCAT(ROUTINE_SCHEMA) = 'i_s_routines_test'
|
WHERE ROUTINE_NAME = 'test_func5';
|
||||||
AND ROUTINE_NAME = 'test_func5';
|
|
||||||
SPECIFIC_NAME test_func5
|
SPECIFIC_NAME test_func5
|
||||||
ROUTINE_CATALOG def
|
ROUTINE_CATALOG def
|
||||||
ROUTINE_SCHEMA i_s_routines_test
|
ROUTINE_SCHEMA i_s_routines_test
|
||||||
@ -899,7 +899,19 @@ DATABASE_COLLATION latin1_swedish_ci
|
|||||||
SHOW STATUS LIKE 'handler_read%next';
|
SHOW STATUS LIKE 'handler_read%next';
|
||||||
Variable_name Value
|
Variable_name Value
|
||||||
Handler_read_next 54
|
Handler_read_next 54
|
||||||
Handler_read_rnd_next 55
|
Handler_read_rnd_next 2
|
||||||
|
#
|
||||||
|
# We cannot use the index due to CONCAT(), and filtering by ROUTINE_NAME
|
||||||
|
# does not work either since ROUTINE_NAME = 'not_existing_proc'. See
|
||||||
|
# the difference in counters in comparison to the previous test
|
||||||
|
FLUSH STATUS;
|
||||||
|
SELECT * FROM INFORMATION_SCHEMA.ROUTINES
|
||||||
|
WHERE CONCAT(ROUTINE_SCHEMA) = 'i_s_routines_test'
|
||||||
|
AND ROUTINE_NAME = 'not_existing_proc';
|
||||||
|
SHOW STATUS LIKE 'handler_read%next';
|
||||||
|
Variable_name Value
|
||||||
|
Handler_read_next 54
|
||||||
|
Handler_read_rnd_next 1
|
||||||
#
|
#
|
||||||
# Now the index must be used
|
# Now the index must be used
|
||||||
FLUSH STATUS;
|
FLUSH STATUS;
|
||||||
|
@ -263,13 +263,24 @@ USE i_s_routines_test;
|
|||||||
CREATE FUNCTION test_func5 (s CHAR(20)) RETURNS VARCHAR(30)
|
CREATE FUNCTION test_func5 (s CHAR(20)) RETURNS VARCHAR(30)
|
||||||
RETURN CONCAT('XYZ, ' ,s);
|
RETURN CONCAT('XYZ, ' ,s);
|
||||||
|
|
||||||
|
|
||||||
--echo #
|
--echo #
|
||||||
--echo # We cannot use the index due to CONCAT()
|
--echo # We cannot use the index due to missing condition on SPECIFIC_SCHEMA,
|
||||||
|
--echo # but we will use ROUTINE_NAME for filtering records from mysql.proc
|
||||||
FLUSH STATUS;
|
FLUSH STATUS;
|
||||||
--replace_column 24 <created> 25 <modified>
|
--replace_column 24 <created> 25 <modified>
|
||||||
|
query_vertical SELECT * FROM INFORMATION_SCHEMA.ROUTINES
|
||||||
|
WHERE ROUTINE_NAME = 'test_func5';
|
||||||
|
SHOW STATUS LIKE 'handler_read%next';
|
||||||
|
|
||||||
|
--echo #
|
||||||
|
--echo # We cannot use the index due to CONCAT(), and filtering by ROUTINE_NAME
|
||||||
|
--echo # does not work either since ROUTINE_NAME = 'not_existing_proc'. See
|
||||||
|
--echo # the difference in counters in comparison to the previous test
|
||||||
|
FLUSH STATUS;
|
||||||
query_vertical SELECT * FROM INFORMATION_SCHEMA.ROUTINES
|
query_vertical SELECT * FROM INFORMATION_SCHEMA.ROUTINES
|
||||||
WHERE CONCAT(ROUTINE_SCHEMA) = 'i_s_routines_test'
|
WHERE CONCAT(ROUTINE_SCHEMA) = 'i_s_routines_test'
|
||||||
AND ROUTINE_NAME = 'test_func5';
|
AND ROUTINE_NAME = 'not_existing_proc';
|
||||||
SHOW STATUS LIKE 'handler_read%next';
|
SHOW STATUS LIKE 'handler_read%next';
|
||||||
|
|
||||||
--echo #
|
--echo #
|
||||||
|
@ -6445,6 +6445,64 @@ static inline void copy_field_as_string(Field *to_field, Field *from_field)
|
|||||||
}
|
}
|
||||||
|
|
||||||
|
|
||||||
|
/**
|
||||||
|
@brief When scanning mysql.proc check if we should skip this record or even
|
||||||
|
stop the scan
|
||||||
|
|
||||||
|
@param name_field_charset mysql.proc.name field charset info
|
||||||
|
@param lookup values from the WHERE clause which are
|
||||||
|
used for the index lookup
|
||||||
|
@param db mysql.proc.db field value of
|
||||||
|
the current record
|
||||||
|
@param name mysql.proc.name field value of
|
||||||
|
the current record
|
||||||
|
|
||||||
|
@return Result
|
||||||
|
@retval -1 The record is match (do further processing)
|
||||||
|
@retval 0 Skip this record, it doesn't match.
|
||||||
|
@retval HA_ERR_END_OF_FILE Stop scanning, no further matches possible
|
||||||
|
*/
|
||||||
|
|
||||||
|
int check_proc_record(const CHARSET_INFO *name_field_charset,
|
||||||
|
const LOOKUP_FIELD_VALUES *lookup,
|
||||||
|
const LEX_CSTRING &db,
|
||||||
|
const LEX_CSTRING &name)
|
||||||
|
{
|
||||||
|
if (lookup->db_value.str && cmp(lookup->db_value, db))
|
||||||
|
{
|
||||||
|
/*
|
||||||
|
We have the name of target database. If we got a non-matching
|
||||||
|
record, this means we've finished reading matching mysql.proc records
|
||||||
|
*/
|
||||||
|
return HA_ERR_END_OF_FILE;
|
||||||
|
}
|
||||||
|
|
||||||
|
if (lookup->table_value.str)
|
||||||
|
{
|
||||||
|
if ((my_ci_strnncoll(name_field_charset,
|
||||||
|
(const uchar *) lookup->table_value.str,
|
||||||
|
lookup->table_value.length,
|
||||||
|
(const uchar *) name.str, name.length, 0)))
|
||||||
|
{
|
||||||
|
/* Routine name doesn't match. */
|
||||||
|
if (lookup->db_value.str)
|
||||||
|
{
|
||||||
|
/*
|
||||||
|
We're using index lookup. A non-matching record means we've
|
||||||
|
finished reading matches.
|
||||||
|
*/
|
||||||
|
return HA_ERR_END_OF_FILE;
|
||||||
|
}
|
||||||
|
else
|
||||||
|
{
|
||||||
|
/* The routine name doesn't match, but we're scanning all databases */
|
||||||
|
return 0; /* Continue scanning */
|
||||||
|
}
|
||||||
|
}
|
||||||
|
}
|
||||||
|
return -1; /* This is a match */
|
||||||
|
}
|
||||||
|
|
||||||
/**
|
/**
|
||||||
@brief Store record into I_S.PARAMETERS table
|
@brief Store record into I_S.PARAMETERS table
|
||||||
|
|
||||||
@ -6476,6 +6534,7 @@ int store_schema_params(THD *thd, TABLE *table, TABLE *proc_table,
|
|||||||
bool free_sp_head;
|
bool free_sp_head;
|
||||||
bool error= 0;
|
bool error= 0;
|
||||||
sql_mode_t sql_mode;
|
sql_mode_t sql_mode;
|
||||||
|
int rc;
|
||||||
DBUG_ENTER("store_schema_params");
|
DBUG_ENTER("store_schema_params");
|
||||||
|
|
||||||
bzero((char*) &tbl, sizeof(TABLE));
|
bzero((char*) &tbl, sizeof(TABLE));
|
||||||
@ -6485,13 +6544,10 @@ int store_schema_params(THD *thd, TABLE *table, TABLE *proc_table,
|
|||||||
proc_table->field[MYSQL_PROC_FIELD_DB]->val_str_nopad(thd->mem_root, &db);
|
proc_table->field[MYSQL_PROC_FIELD_DB]->val_str_nopad(thd->mem_root, &db);
|
||||||
proc_table->field[MYSQL_PROC_FIELD_NAME]->val_str_nopad(thd->mem_root, &name);
|
proc_table->field[MYSQL_PROC_FIELD_NAME]->val_str_nopad(thd->mem_root, &name);
|
||||||
|
|
||||||
if (lookup->db_value.str)
|
CHARSET_INFO *name_cs= proc_table->field[MYSQL_PROC_FIELD_NAME]->charset();
|
||||||
{
|
|
||||||
if (cmp(lookup->db_value, db))
|
if ((rc= check_proc_record(name_cs, lookup, db, name)) != -1)
|
||||||
DBUG_RETURN(HA_ERR_END_OF_FILE);
|
DBUG_RETURN(rc); /* either HA_ERR_END_OF_FILE or 0 if name didn't match */
|
||||||
if (lookup->table_value.str && cmp(lookup->table_value, name))
|
|
||||||
DBUG_RETURN(HA_ERR_END_OF_FILE);
|
|
||||||
}
|
|
||||||
|
|
||||||
proc_table->field[MYSQL_PROC_FIELD_DEFINER]->val_str_nopad(thd->mem_root, &definer);
|
proc_table->field[MYSQL_PROC_FIELD_DEFINER]->val_str_nopad(thd->mem_root, &definer);
|
||||||
sql_mode= (sql_mode_t) proc_table->field[MYSQL_PROC_FIELD_SQL_MODE]->val_int();
|
sql_mode= (sql_mode_t) proc_table->field[MYSQL_PROC_FIELD_SQL_MODE]->val_int();
|
||||||
@ -6605,23 +6661,14 @@ int store_schema_proc(THD *thd, TABLE *table, TABLE *proc_table,
|
|||||||
const Sp_handler *sph;
|
const Sp_handler *sph;
|
||||||
LEX_CSTRING db, name, definer, returns= empty_clex_str;
|
LEX_CSTRING db, name, definer, returns= empty_clex_str;
|
||||||
const char *wild= thd->lex->wild ? thd->lex->wild->ptr() : NullS;
|
const char *wild= thd->lex->wild ? thd->lex->wild->ptr() : NullS;
|
||||||
|
int rc;
|
||||||
|
|
||||||
proc_table->field[MYSQL_PROC_FIELD_DB]->val_str_nopad(thd->mem_root, &db);
|
proc_table->field[MYSQL_PROC_FIELD_DB]->val_str_nopad(thd->mem_root, &db);
|
||||||
proc_table->field[MYSQL_PROC_FIELD_NAME]->val_str_nopad(thd->mem_root, &name);
|
proc_table->field[MYSQL_PROC_FIELD_NAME]->val_str_nopad(thd->mem_root, &name);
|
||||||
|
|
||||||
if (lookup->db_value.str)
|
CHARSET_INFO *name_cs= proc_table->field[MYSQL_PROC_FIELD_NAME]->charset();
|
||||||
{
|
if ((rc= check_proc_record(name_cs, lookup, db, name)) != -1)
|
||||||
if (cmp(lookup->db_value, db))
|
return rc; /* either HA_ERR_END_OF_FILE or 0 if name didn't match */
|
||||||
return HA_ERR_END_OF_FILE;
|
|
||||||
if (lookup->table_value.str)
|
|
||||||
{
|
|
||||||
CHARSET_INFO *cs= proc_table->field[MYSQL_PROC_FIELD_NAME]->charset();
|
|
||||||
if (my_ci_strnncoll(cs, (const uchar*)lookup->table_value.str,
|
|
||||||
lookup->table_value.length,
|
|
||||||
(const uchar*) name.str, name.length, 0))
|
|
||||||
return HA_ERR_END_OF_FILE;
|
|
||||||
}
|
|
||||||
}
|
|
||||||
|
|
||||||
proc_table->field[MYSQL_PROC_FIELD_DEFINER]->val_str_nopad(thd->mem_root, &definer);
|
proc_table->field[MYSQL_PROC_FIELD_DEFINER]->val_str_nopad(thd->mem_root, &definer);
|
||||||
sph= Sp_handler::handler_mysql_proc((enum_sp_type)
|
sph= Sp_handler::handler_mysql_proc((enum_sp_type)
|
||||||
|
Loading…
x
Reference in New Issue
Block a user