From 601c577142639d7bde947d071ca944c16920340c Mon Sep 17 00:00:00 2001 From: Vladislav Vaintroub Date: Wed, 17 Mar 2021 23:22:01 +0100 Subject: [PATCH] MDEV-9077 - port sys schema to MariaDB - Innodb is not always available, which means t is not always possible to use innodb system variables, or innodb information schema tables. Thus creation of objects that use Innodb information_schema is enclosed into BEGIN NOT ATOMIC blocks with dummy SQLEXCEPTION handler. - sys_config table uses Aria, just like other system tables. - several tables that exist in MySQL, do not exist in MariaDB performance_schema.replication_applier_status, mysql.slave_master_info, mysql.slave_relay_log_info --- scripts/sys_schema/.gitignore | 1 - scripts/sys_schema/after_setup.sql | 2 + scripts/sys_schema/functions/format_path.sql | 21 ++++--- .../sys_schema/functions/format_path_57.sql | 58 +++++++++++++----- .../sys_schema/functions/sys_get_config.sql | 4 ++ scripts/sys_schema/procedures/diagnostics.sql | 60 +------------------ .../procedures/ps_setup_show_enabled.sql | 4 +- scripts/sys_schema/tables/sys_config.sql | 4 +- .../sys_schema/tables/sys_config_data_57.sql | 2 + .../i_s/innodb_buffer_stats_by_schema.sql | 9 +++ .../i_s/innodb_buffer_stats_by_table.sql | 5 ++ .../views/i_s/innodb_lock_waits.sql | 8 ++- .../i_s/x_innodb_buffer_stats_by_schema.sql | 11 +++- .../i_s/x_innodb_buffer_stats_by_table.sql | 10 +++- .../views/i_s/x_innodb_lock_waits.sql | 6 ++ scripts/sys_schema/views/p_s/metrics.sql | 7 ++- .../schema_table_statistics_with_buffer.sql | 8 ++- .../x_schema_table_statistics_with_buffer.sql | 8 ++- 18 files changed, 134 insertions(+), 94 deletions(-) delete mode 100644 scripts/sys_schema/.gitignore diff --git a/scripts/sys_schema/.gitignore b/scripts/sys_schema/.gitignore deleted file mode 100644 index e8e450bed89..00000000000 --- a/scripts/sys_schema/.gitignore +++ /dev/null @@ -1 +0,0 @@ -gen/ diff --git a/scripts/sys_schema/after_setup.sql b/scripts/sys_schema/after_setup.sql index 61f3cc54d3a..833f84c4120 100644 --- a/scripts/sys_schema/after_setup.sql +++ b/scripts/sys_schema/after_setup.sql @@ -14,3 +14,5 @@ -- Foundation, Inc., 51 Franklin St, Fifth Floor, Boston, MA 02110-1301 USA SET @@sql_log_bin = @sql_log_bin; +use mysql; + diff --git a/scripts/sys_schema/functions/format_path.sql b/scripts/sys_schema/functions/format_path.sql index 1db59526391..59704d11c2b 100644 --- a/scripts/sys_schema/functions/format_path.sql +++ b/scripts/sys_schema/functions/format_path.sql @@ -67,6 +67,8 @@ CREATE DEFINER='root'@'localhost' FUNCTION format_path ( BEGIN DECLARE v_path VARCHAR(512); DECLARE v_undo_dir VARCHAR(1024); + DECLARE v_innodb_data_home_dir VARCHAR(1024); + DECLARE v_innodb_log_group_home_dir VARCHAR(1024); DECLARE path_separator CHAR(1) DEFAULT '/'; @@ -82,20 +84,21 @@ BEGIN END IF; -- @@global.innodb_undo_directory is only set when separate undo logs are used - SET v_undo_dir = IFNULL((SELECT VARIABLE_VALUE FROM information_schema.GLOBAL_VARIABLES WHERE VARIABLE_NAME = 'innodb_undo_directory'), ''); - + SET v_undo_dir = IFNULL((SELECT VARIABLE_VALUE FROM information_schema.global_variables WHERE VARIABLE_NAME = 'innodb_undo_directory'), ''); + SET v_innodb_data_home_dir= IFNULL((SELECT VARIABLE_VALUE FROM information_schema.global_variables WHERE VARIABLE_NAME = 'innodb_data_home_dir'), ''); + SET v_innodb_log_group_home_dir= IFNULL((SELECT VARIABLE_VALUE FROM information_schema.global_variables WHERE VARIABLE_NAME = 'innodb_log_group_home_dir'), ''); IF v_path IS NULL THEN RETURN NULL; ELSEIF v_path LIKE CONCAT(@@global.datadir, IF(SUBSTRING(@@global.datadir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN SET v_path = REPLACE(v_path, @@global.datadir, CONCAT('@@datadir', IF(SUBSTRING(@@global.datadir, -1) = path_separator, path_separator, ''))); ELSEIF v_path LIKE CONCAT(@@global.tmpdir, IF(SUBSTRING(@@global.tmpdir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN SET v_path = REPLACE(v_path, @@global.tmpdir, CONCAT('@@tmpdir', IF(SUBSTRING(@@global.tmpdir, -1) = path_separator, path_separator, ''))); - ELSEIF v_path LIKE CONCAT(@@global.slave_load_tmpdir, IF(SUBSTRING(@@global.slave_load_tmpdir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN - SET v_path = REPLACE(v_path, @@global.slave_load_tmpdir, CONCAT('@@slave_load_tmpdir', IF(SUBSTRING(@@global.slave_load_tmpdir, -1) = path_separator, path_separator, ''))); - ELSEIF v_path LIKE CONCAT(@@global.innodb_data_home_dir, IF(SUBSTRING(@@global.innodb_data_home_dir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN - SET v_path = REPLACE(v_path, @@global.innodb_data_home_dir, CONCAT('@@innodb_data_home_dir', IF(SUBSTRING(@@global.innodb_data_home_dir, -1) = path_separator, path_separator, ''))); - ELSEIF v_path LIKE CONCAT(@@global.innodb_log_group_home_dir, IF(SUBSTRING(@@global.innodb_log_group_home_dir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN - SET v_path = REPLACE(v_path, @@global.innodb_log_group_home_dir, CONCAT('@@innodb_log_group_home_dir', IF(SUBSTRING(@@global.innodb_log_group_home_dir, -1) = path_separator, path_separator, ''))); +# ELSEIF v_path LIKE CONCAT(@@global.slave_load_tmpdir, IF(SUBSTRING(@@global.slave_load_tmpdir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN +# SET v_path = REPLACE(v_path, @@global.slave_load_tmpdir, CONCAT('@@slave_load_tmpdir', IF(SUBSTRING(@@global.slave_load_tmpdir, -1) = path_separator, path_separator, ''))); + ELSEIF v_path LIKE CONCAT(v_innodb_data_home_dir, IF(SUBSTRING(v_innodb_data_home_dir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN + SET v_path = REPLACE(v_path, v_innodb_data_home_dir, CONCAT('@@innodb_data_home_dir', IF(SUBSTRING(v_innodb_data_home_dir, -1) = path_separator, path_separator, ''))); + ELSEIF v_path LIKE CONCAT(v_innodb_log_group_home_dir, IF(SUBSTRING(v_innodb_log_group_home_dir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN + SET v_path = REPLACE(v_path, v_innodb_log_group_home_dir, CONCAT('@@innodb_log_group_home_dir', IF(SUBSTRING(v_innodb_log_group_home_dir, -1) = path_separator, path_separator, ''))); ELSEIF v_path LIKE CONCAT(v_undo_dir, IF(SUBSTRING(v_undo_dir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN SET v_path = REPLACE(v_path, v_undo_dir, CONCAT('@@innodb_undo_directory', IF(SUBSTRING(v_undo_dir, -1) = path_separator, path_separator, ''))); ELSEIF v_path LIKE CONCAT(@@global.basedir, IF(SUBSTRING(@@global.basedir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN @@ -105,4 +108,4 @@ BEGIN RETURN v_path; END$$ -DELIMITER ; +DELIMITER ; \ No newline at end of file diff --git a/scripts/sys_schema/functions/format_path_57.sql b/scripts/sys_schema/functions/format_path_57.sql index f03f1063cfd..61c496fd605 100644 --- a/scripts/sys_schema/functions/format_path_57.sql +++ b/scripts/sys_schema/functions/format_path_57.sql @@ -65,8 +65,8 @@ CREATE DEFINER='root'@'localhost' FUNCTION format_path ( DETERMINISTIC NO SQL BEGIN + DECLARE v_dir VARCHAR(1024); DECLARE v_path VARCHAR(512); - DECLARE v_undo_dir VARCHAR(1024); DECLARE path_separator CHAR(1) DEFAULT '/'; @@ -82,27 +82,55 @@ BEGIN END IF; -- @@global.innodb_undo_directory is only set when separate undo logs are used - SET v_undo_dir = IFNULL((SELECT VARIABLE_VALUE FROM performance_schema.global_variables WHERE VARIABLE_NAME = 'innodb_undo_directory'), ''); - + + SET v_dir= IFNULL((SELECT VARIABLE_VALUE FROM information_schema.global_variables WHERE VARIABLE_NAME = 'innodb_data_home_dir'), ''); + IF v_path IS NULL THEN RETURN NULL; - ELSEIF v_path LIKE CONCAT(@@global.datadir, IF(SUBSTRING(@@global.datadir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN + END IF; + + IF v_path LIKE CONCAT(@@global.datadir, IF(SUBSTRING(@@global.datadir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN SET v_path = REPLACE(v_path, @@global.datadir, CONCAT('@@datadir', IF(SUBSTRING(@@global.datadir, -1) = path_separator, path_separator, ''))); - ELSEIF v_path LIKE CONCAT(@@global.tmpdir, IF(SUBSTRING(@@global.tmpdir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN + RETURN v_path; + END IF; + + IF v_path LIKE CONCAT(@@global.tmpdir, IF(SUBSTRING(@@global.tmpdir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN SET v_path = REPLACE(v_path, @@global.tmpdir, CONCAT('@@tmpdir', IF(SUBSTRING(@@global.tmpdir, -1) = path_separator, path_separator, ''))); - ELSEIF v_path LIKE CONCAT(@@global.slave_load_tmpdir, IF(SUBSTRING(@@global.slave_load_tmpdir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN - SET v_path = REPLACE(v_path, @@global.slave_load_tmpdir, CONCAT('@@slave_load_tmpdir', IF(SUBSTRING(@@global.slave_load_tmpdir, -1) = path_separator, path_separator, ''))); - ELSEIF v_path LIKE CONCAT(@@global.innodb_data_home_dir, IF(SUBSTRING(@@global.innodb_data_home_dir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN - SET v_path = REPLACE(v_path, @@global.innodb_data_home_dir, CONCAT('@@innodb_data_home_dir', IF(SUBSTRING(@@global.innodb_data_home_dir, -1) = path_separator, path_separator, ''))); - ELSEIF v_path LIKE CONCAT(@@global.innodb_log_group_home_dir, IF(SUBSTRING(@@global.innodb_log_group_home_dir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN - SET v_path = REPLACE(v_path, @@global.innodb_log_group_home_dir, CONCAT('@@innodb_log_group_home_dir', IF(SUBSTRING(@@global.innodb_log_group_home_dir, -1) = path_separator, path_separator, ''))); - ELSEIF v_path LIKE CONCAT(v_undo_dir, IF(SUBSTRING(v_undo_dir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN - SET v_path = REPLACE(v_path, v_undo_dir, CONCAT('@@innodb_undo_directory', IF(SUBSTRING(v_undo_dir, -1) = path_separator, path_separator, ''))); - ELSEIF v_path LIKE CONCAT(@@global.basedir, IF(SUBSTRING(@@global.basedir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN + RETURN v_path; + END IF; + + + SET v_dir= IFNULL((SELECT VARIABLE_VALUE FROM information_schema.global_variables WHERE VARIABLE_NAME = 'innodb_data_home_dir'), ''); + IF v_path LIKE CONCAT(v_dir, IF(SUBSTRING(v_dir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN + SET v_path = REPLACE(v_path, v_dir, CONCAT('@@innodb_data_home_dir', IF(SUBSTRING(v_dir, -1) = path_separator, path_separator, ''))); + RETURN v_path; + END IF; + + SET v_dir= IFNULL((SELECT VARIABLE_VALUE FROM information_schema.global_variables WHERE VARIABLE_NAME = 'innodb_log_group_home_dir'), ''); + IF v_path LIKE CONCAT(v_dir, IF(SUBSTRING(v_dir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN + SET v_path = REPLACE(v_path, v_dir, CONCAT('@@innodb_log_group_home_dir', IF(SUBSTRING(v_dir, -1) = path_separator, path_separator, ''))); + RETURN v_path; + END IF; + + SET v_dir= IFNULL((SELECT VARIABLE_VALUE FROM information_schema.global_variables WHERE VARIABLE_NAME = 'slave_load_tmpdir'), ''); + IF v_path LIKE CONCAT(v_dir, IF(SUBSTRING(v_dir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN + SET v_path = REPLACE(v_path, v_dir, CONCAT('@@slave_load_tmpdir', IF(SUBSTRING(v_dir, -1) = path_separator, path_separator, ''))); + RETURN v_path; + END IF; + + + SET v_dir = IFNULL((SELECT VARIABLE_VALUE FROM information_schema.global_variables WHERE VARIABLE_NAME = 'innodb_undo_directory'), ''); + IF v_path LIKE CONCAT(v_dir, IF(SUBSTRING(v_dir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN + SET v_path = REPLACE(v_path, v_dir, CONCAT('@@innodb_undo_directory', IF(SUBSTRING(v_dir, -1) = path_separator, path_separator, ''))); + RETURN v_path; + END IF; + + IF v_path LIKE CONCAT(@@global.basedir, IF(SUBSTRING(@@global.basedir, -1) = path_separator, '%', CONCAT(path_separator, '%'))) ESCAPE '|' THEN SET v_path = REPLACE(v_path, @@global.basedir, CONCAT('@@basedir', IF(SUBSTRING(@@global.basedir, -1) = path_separator, path_separator, ''))); + RETURN v_path; END IF; RETURN v_path; END$$ -DELIMITER ; +DELIMITER ; \ No newline at end of file diff --git a/scripts/sys_schema/functions/sys_get_config.sql b/scripts/sys_schema/functions/sys_get_config.sql index cca2bc63700..1064a8f4ee8 100644 --- a/scripts/sys_schema/functions/sys_get_config.sql +++ b/scripts/sys_schema/functions/sys_get_config.sql @@ -83,9 +83,13 @@ CREATE DEFINER='root'@'localhost' FUNCTION sys_get_config ( READS SQL DATA BEGIN DECLARE v_value VARCHAR(128) DEFAULT NULL; + DECLARE old_val INTEGER DEFAULT NULL; + SET old_val = @@session.sql_notes; + SET SESSION sql_notes=0; -- Check if we have the variable in the sys.sys_config table SET v_value = (SELECT value FROM sys.sys_config WHERE variable = in_variable_name); + SET SESSION sql_notes=old_val; -- Protection against the variable not existing in sys_config IF (v_value IS NULL) THEN diff --git a/scripts/sys_schema/procedures/diagnostics.sql b/scripts/sys_schema/procedures/diagnostics.sql index ba5bc806e6a..8cccdb68233 100644 --- a/scripts/sys_schema/procedures/diagnostics.sql +++ b/scripts/sys_schema/procedures/diagnostics.sql @@ -272,8 +272,6 @@ BEGIN UNION ALL SELECT 'Datadir' AS 'Name', @@global.datadir AS 'Value' UNION ALL - SELECT 'Server UUID' AS 'Name', @@global.server_uuid AS 'Value' - UNION ALL SELECT REPEAT('-', 23) AS 'Name', v_banner AS 'Value' UNION ALL SELECT 'MySQL Version' AS 'Name', VERSION() AS 'Value' @@ -307,10 +305,7 @@ BEGIN 'YES', 'NO' ), - v_has_replication = /*!50707 IF(v_has_ps_replication = 'YES', IF((SELECT COUNT(*) FROM performance_schema.replication_connection_status) > 0, 'YES', 'NO'),*/ - IF(@@master_info_repository = 'TABLE', IF((SELECT COUNT(*) FROM mysql.slave_master_info) > 0, 'YES', 'NO'), - IF(@@relay_log_info_repository = 'TABLE', IF((SELECT COUNT(*) FROM mysql.slave_relay_log_info) > 0, 'YES', 'NO'), - 'MAYBE'))/*!50707 )*/, + v_has_replication = 'MAYBE', v_has_metrics = IF(v_has_ps = 'YES' OR (sys.version_major() = 5 AND sys.version_minor() = 6), 'YES', 'NO'), v_has_ps_vars = 'NO'; @@ -576,23 +571,6 @@ BEGIN SELECT 'Replication - Applier Configuration' AS 'The following output is:'; SELECT * FROM performance_schema.replication_applier_configuration ORDER BY CHANNEL_NAME; END IF; - - IF (@@master_info_repository = 'TABLE') THEN - SELECT 'Replication - Master Info Repository Configuration' AS 'The following output is:'; - -- Can't just do SELECT * as the password may be present in plain text - -- Don't include binary log file and position as that will be determined in each iteration as well - SELECT /*!50706 Channel_name, */Host, User_name, Port, Connect_retry, - Enabled_ssl, Ssl_ca, Ssl_capath, Ssl_cert, Ssl_cipher, Ssl_key, Ssl_verify_server_cert, - Heartbeat, Bind, Ignored_server_ids, Uuid, Retry_count, Ssl_crl, Ssl_crlpath, - Tls_version, Enabled_auto_position - FROM mysql.slave_master_info/*!50706 ORDER BY Channel_name*/; - END IF; - - IF (@@relay_log_info_repository = 'TABLE') THEN - SELECT 'Replication - Relay Log Repository Configuration' AS 'The following output is:'; - SELECT /*!50706 Channel_name, */Sql_delay, Number_of_workers, Id - FROM mysql.slave_relay_log_info/*!50706 ORDER BY Channel_name*/; - END IF; END IF; @@ -696,38 +674,6 @@ BEGIN IF (v_has_replication <> 'NO') THEN SELECT 'SHOW SLAVE STATUS' AS 'The following output is:'; SHOW SLAVE STATUS; - - IF (v_has_ps_replication = 'YES') THEN - SELECT 'Replication Connection Status' AS 'The following output is:'; - SELECT * FROM performance_schema.replication_connection_status; - - SELECT 'Replication Applier Status' AS 'The following output is:'; - SELECT * FROM performance_schema.replication_applier_status ORDER BY CHANNEL_NAME; - - SELECT 'Replication Applier Status - Coordinator' AS 'The following output is:'; - SELECT * FROM performance_schema.replication_applier_status_by_coordinator ORDER BY CHANNEL_NAME; - - SELECT 'Replication Applier Status - Worker' AS 'The following output is:'; - SELECT * FROM performance_schema.replication_applier_status_by_worker ORDER BY CHANNEL_NAME, WORKER_ID; - END IF; - - IF (@@master_info_repository = 'TABLE') THEN - SELECT 'Replication - Master Log Status' AS 'The following output is:'; - SELECT Master_log_name, Master_log_pos FROM mysql.slave_master_info; - END IF; - - IF (@@relay_log_info_repository = 'TABLE') THEN - SELECT 'Replication - Relay Log Status' AS 'The following output is:'; - SELECT sys.format_path(Relay_log_name) AS Relay_log_name, Relay_log_pos, Master_log_name, Master_log_pos FROM mysql.slave_relay_log_info; - - SELECT 'Replication - Worker Status' AS 'The following output is:'; - SELECT Id, sys.format_path(Relay_log_name) AS Relay_log_name, Relay_log_pos, Master_log_name, Master_log_pos, - sys.format_path(Checkpoint_relay_log_name) AS Checkpoint_relay_log_name, Checkpoint_relay_log_pos, - Checkpoint_master_log_name, Checkpoint_master_log_pos, Checkpoint_seqno, Checkpoint_group_size, - HEX(Checkpoint_group_bitmap) AS Checkpoint_group_bitmap/*!50706 , Channel_name*/ - FROM mysql.slave_worker_info - ORDER BY /*!50706 Channel_name, */Id; - END IF; END IF; -- We need one table per output as a temporary table cannot be opened twice in the same query, and we need to @@ -739,7 +685,7 @@ BEGIN CALL sys.execute_prepared_stmt(CONCAT('CREATE TEMPORARY TABLE ', v_table_name, ' ( Variable_name VARCHAR(193) NOT NULL, Variable_value VARCHAR(1024), - Type VARCHAR(225) NOT NULL, + Type VARCHAR(100) NOT NULL, Enabled ENUM(''YES'', ''NO'', ''PARTIAL'') NOT NULL, PRIMARY KEY (Type, Variable_name) ) ENGINE = InnoDB DEFAULT CHARSET=utf8')); @@ -784,7 +730,7 @@ SELECT ''UNIX_TIMESTAMP()'' AS Variable_name, ROUND(UNIX_TIMESTAMP(NOW(3)), 3) A -- Prepare the query to retrieve the summary CALL sys.execute_prepared_stmt( - CONCAT('(SELECT Variable_value INTO @sys.diagnostics.output_time FROM ', v_table_name, ' WHERE Type = ''System Time'' AND Variable_name = ''UNIX_TIMESTAMP()'')') + CONCAT('SELECT Variable_value INTO @sys.diagnostics.output_time FROM ', v_table_name, ' WHERE Type = ''System Time'' AND Variable_name = ''UNIX_TIMESTAMP()''') ); SET v_output_time = @sys.diagnostics.output_time; diff --git a/scripts/sys_schema/procedures/ps_setup_show_enabled.sql b/scripts/sys_schema/procedures/ps_setup_show_enabled.sql index 5f0031cbb95..7b2c2644358 100644 --- a/scripts/sys_schema/procedures/ps_setup_show_enabled.sql +++ b/scripts/sys_schema/procedures/ps_setup_show_enabled.sql @@ -128,7 +128,7 @@ BEGIN -- in the setup_actors table were enabled. SELECT CONCAT('\'', user, '\'@\'', host, '\'') AS enabled_users FROM performance_schema.setup_actors - /*!50706 WHERE enabled = 'YES' */ + WHERE enabled = 'YES' ORDER BY enabled_users; SELECT object_type, @@ -150,7 +150,7 @@ BEGIN REPLACE(name, 'thread/', '')) AS enabled_threads, TYPE AS thread_type FROM performance_schema.threads - WHERE INSTRUMENTED = 'YES' + WHERE INSTRUMENTED = 'YES' AND name <> 'thread/innodb/thread_pool_thread' ORDER BY enabled_threads; END IF; diff --git a/scripts/sys_schema/tables/sys_config.sql b/scripts/sys_schema/tables/sys_config.sql index 2d2e9b843a3..65b8e686319 100644 --- a/scripts/sys_schema/tables/sys_config.sql +++ b/scripts/sys_schema/tables/sys_config.sql @@ -24,4 +24,6 @@ CREATE TABLE IF NOT EXISTS sys_config ( value VARCHAR(128), set_time TIMESTAMP DEFAULT CURRENT_TIMESTAMP ON UPDATE CURRENT_TIMESTAMP, set_by VARCHAR(128) -) ENGINE = InnoDB; +) ENGINE = Aria transactional=1; + + diff --git a/scripts/sys_schema/tables/sys_config_data_57.sql b/scripts/sys_schema/tables/sys_config_data_57.sql index d36451c1aad..4abbb0b1556 100644 --- a/scripts/sys_schema/tables/sys_config_data_57.sql +++ b/scripts/sys_schema/tables/sys_config_data_57.sql @@ -22,3 +22,5 @@ INSERT IGNORE INTO sys.sys_config (variable, value) VALUES ('diagnostics.allow_i_s_tables', 'OFF'), ('diagnostics.include_raw', 'OFF'), ('ps_thread_trx_info.max_length', 65535); + +FLUSH TABLES sys.sys_config; diff --git a/scripts/sys_schema/views/i_s/innodb_buffer_stats_by_schema.sql b/scripts/sys_schema/views/i_s/innodb_buffer_stats_by_schema.sql index 0c8c5bdde05..d3dc21d2ce4 100644 --- a/scripts/sys_schema/views/i_s/innodb_buffer_stats_by_schema.sql +++ b/scripts/sys_schema/views/i_s/innodb_buffer_stats_by_schema.sql @@ -30,6 +30,12 @@ -- +--------------------------+------------+------------+-------+--------------+-----------+-------------+ -- +DELIMITER $$ + +BEGIN NOT ATOMIC + DECLARE EXIT HANDLER FOR SQLEXCEPTION + BEGIN + END; CREATE OR REPLACE ALGORITHM = TEMPTABLE DEFINER = 'root'@'localhost' @@ -54,3 +60,6 @@ SELECT IF(LOCATE('.', ibp.table_name) = 0, 'InnoDB System', REPLACE(SUBSTRING_IN WHERE table_name IS NOT NULL GROUP BY object_schema ORDER BY SUM(IF(ibp.compressed_size = 0, 16384, compressed_size)) DESC; +END$$ +DELIMITER ; + diff --git a/scripts/sys_schema/views/i_s/innodb_buffer_stats_by_table.sql b/scripts/sys_schema/views/i_s/innodb_buffer_stats_by_table.sql index 9c3fa55812c..6a479370e2d 100644 --- a/scripts/sys_schema/views/i_s/innodb_buffer_stats_by_table.sql +++ b/scripts/sys_schema/views/i_s/innodb_buffer_stats_by_table.sql @@ -34,6 +34,9 @@ -- +--------------------------+------------------------------------+------------+-----------+-------+--------------+-----------+-------------+ -- +DELIMITER $$ +BEGIN NOT ATOMIC +DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN END; CREATE OR REPLACE ALGORITHM = TEMPTABLE DEFINER = 'root'@'localhost' @@ -60,3 +63,5 @@ SELECT IF(LOCATE('.', ibp.table_name) = 0, 'InnoDB System', REPLACE(SUBSTRING_IN WHERE table_name IS NOT NULL GROUP BY object_schema, object_name ORDER BY SUM(IF(ibp.compressed_size = 0, 16384, compressed_size)) DESC; +END$$ +DELIMITER ; \ No newline at end of file diff --git a/scripts/sys_schema/views/i_s/innodb_lock_waits.sql b/scripts/sys_schema/views/i_s/innodb_lock_waits.sql index a821a1dcf94..d19e8f07fee 100644 --- a/scripts/sys_schema/views/i_s/innodb_lock_waits.sql +++ b/scripts/sys_schema/views/i_s/innodb_lock_waits.sql @@ -51,7 +51,11 @@ -- sql_kill_blocking_connection: KILL 4 -- 1 row in set (0.01 sec) -- - +DELIMITER $$ +BEGIN NOT ATOMIC + DECLARE EXIT HANDLER FOR SQLEXCEPTION + BEGIN + END; CREATE OR REPLACE ALGORITHM = TEMPTABLE DEFINER = 'root'@'localhost' @@ -116,3 +120,5 @@ SELECT r.trx_wait_started AS wait_started, INNER JOIN information_schema.innodb_locks bl ON bl.lock_id = w.blocking_lock_id INNER JOIN information_schema.innodb_locks rl ON rl.lock_id = w.requested_lock_id ORDER BY r.trx_wait_started; + END$$ +DELIMITER ; diff --git a/scripts/sys_schema/views/i_s/x_innodb_buffer_stats_by_schema.sql b/scripts/sys_schema/views/i_s/x_innodb_buffer_stats_by_schema.sql index 6a4e89427b3..ab0d4df692c 100644 --- a/scripts/sys_schema/views/i_s/x_innodb_buffer_stats_by_schema.sql +++ b/scripts/sys_schema/views/i_s/x_innodb_buffer_stats_by_schema.sql @@ -29,6 +29,11 @@ -- +--------------------------+-----------+--------+-------+--------------+-----------+-------------+ -- +DELIMITER $$ +BEGIN NOT ATOMIC + DECLARE EXIT HANDLER FOR SQLEXCEPTION + BEGIN + END; CREATE OR REPLACE ALGORITHM = TEMPTABLE DEFINER = 'root'@'localhost' @@ -46,10 +51,12 @@ SELECT IF(LOCATE('.', ibp.table_name) = 0, 'InnoDB System', REPLACE(SUBSTRING_IN SUM(IF(ibp.compressed_size = 0, 16384, compressed_size)) AS allocated, SUM(ibp.data_size) AS data, COUNT(ibp.page_number) AS pages, - COUNT(IF(ibp.is_hashed = 'YES', 1, NULL)) AS pages_hashed, - COUNT(IF(ibp.is_old = 'YES', 1, NULL)) AS pages_old, + COUNT(IF(ibp.is_hashed, 1, NULL)) AS pages_hashed, + COUNT(IF(ibp.is_old, 1, NULL)) AS pages_old, ROUND(IFNULL(SUM(ibp.number_records)/NULLIF(COUNT(DISTINCT ibp.index_name), 0), 0)) AS rows_cached FROM information_schema.innodb_buffer_page ibp WHERE table_name IS NOT NULL GROUP BY object_schema ORDER BY SUM(IF(ibp.compressed_size = 0, 16384, compressed_size)) DESC; +END$$ +DELIMITER ; diff --git a/scripts/sys_schema/views/i_s/x_innodb_buffer_stats_by_table.sql b/scripts/sys_schema/views/i_s/x_innodb_buffer_stats_by_table.sql index 94481a93ef3..ea878fa5a3a 100644 --- a/scripts/sys_schema/views/i_s/x_innodb_buffer_stats_by_table.sql +++ b/scripts/sys_schema/views/i_s/x_innodb_buffer_stats_by_table.sql @@ -33,7 +33,9 @@ -- ... -- +--------------------------+------------------------------------+-----------+--------+-------+--------------+-----------+-------------+ -- - +DELIMITER $$ +BEGIN NOT ATOMIC +DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN END; CREATE OR REPLACE ALGORITHM = TEMPTABLE DEFINER = 'root'@'localhost' @@ -53,10 +55,12 @@ SELECT IF(LOCATE('.', ibp.table_name) = 0, 'InnoDB System', REPLACE(SUBSTRING_IN SUM(IF(ibp.compressed_size = 0, 16384, compressed_size)) AS allocated, SUM(ibp.data_size) AS data, COUNT(ibp.page_number) AS pages, - COUNT(IF(ibp.is_hashed = 'YES', 1, NULL)) AS pages_hashed, - COUNT(IF(ibp.is_old = 'YES', 1, NULL)) AS pages_old, + COUNT(IF(ibp.is_hashed, 1, NULL)) AS pages_hashed, + COUNT(IF(ibp.is_old, 1, NULL)) AS pages_old, ROUND(IFNULL(SUM(ibp.number_records)/NULLIF(COUNT(DISTINCT ibp.index_name), 0), 0)) AS rows_cached FROM information_schema.innodb_buffer_page ibp WHERE table_name IS NOT NULL GROUP BY object_schema, object_name ORDER BY SUM(IF(ibp.compressed_size = 0, 16384, compressed_size)) DESC; +END$$ +DELIMITER ; \ No newline at end of file diff --git a/scripts/sys_schema/views/i_s/x_innodb_lock_waits.sql b/scripts/sys_schema/views/i_s/x_innodb_lock_waits.sql index e1f9c9f969f..4f9b4909282 100644 --- a/scripts/sys_schema/views/i_s/x_innodb_lock_waits.sql +++ b/scripts/sys_schema/views/i_s/x_innodb_lock_waits.sql @@ -52,6 +52,10 @@ -- 1 row in set (0.01 sec) -- +DELIMITER $$ +BEGIN NOT ATOMIC +DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN END; + CREATE OR REPLACE ALGORITHM = TEMPTABLE DEFINER = 'root'@'localhost' @@ -116,3 +120,5 @@ SELECT r.trx_wait_started AS wait_started, INNER JOIN information_schema.innodb_locks bl ON bl.lock_id = w.blocking_lock_id INNER JOIN information_schema.innodb_locks rl ON rl.lock_id = w.requested_lock_id ORDER BY r.trx_wait_started; +END$$ +DELIMITER ; diff --git a/scripts/sys_schema/views/p_s/metrics.sql b/scripts/sys_schema/views/p_s/metrics.sql index 5e0c4de0f22..009e6bb908c 100644 --- a/scripts/sys_schema/views/p_s/metrics.sql +++ b/scripts/sys_schema/views/p_s/metrics.sql @@ -68,6 +68,9 @@ -- | UNIX_TIMESTAMP() | 1433042870.382 ...| System Time | YES | -- +-----------------------------------------------+-------------------------...+--------------------------------------+---------+ -- 412 rows in set (0.02 sec) +DELIMITER $$ +BEGIN NOT ATOMIC +DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN END; CREATE OR REPLACE ALGORITHM = TEMPTABLE @@ -85,7 +88,7 @@ SELECT LOWER(VARIABLE_NAME) AS Variable_name, VARIABLE_VALUE AS Variable_value, ) UNION ALL ( SELECT NAME AS Variable_name, COUNT AS Variable_value, CONCAT('InnoDB Metrics - ', SUBSYSTEM) AS Type, - IF(STATUS = 'enabled', 'YES', 'NO') AS Enabled + 'YES' AS Enabled FROM information_schema.INNODB_METRICS -- Deduplication - some variables exists both in GLOBAL_STATUS and INNODB_METRICS -- Keep the one from GLOBAL_STATUS as it is always enabled and it's more likely to be used for existing tools. @@ -119,3 +122,5 @@ SELECT 'NOW()' AS Variable_name, NOW(3) AS Variable_value, 'System Time' AS Type SELECT 'UNIX_TIMESTAMP()' AS Variable_name, ROUND(UNIX_TIMESTAMP(NOW(3)), 3) AS Variable_value, 'System Time' AS Type, 'YES' AS Enabled ) ORDER BY Type, Variable_name; +END$$ +DELIMITER ; \ No newline at end of file diff --git a/scripts/sys_schema/views/p_s/schema_table_statistics_with_buffer.sql b/scripts/sys_schema/views/p_s/schema_table_statistics_with_buffer.sql index 4c411a5ce66..0b710b1e7ef 100644 --- a/scripts/sys_schema/views/p_s/schema_table_statistics_with_buffer.sql +++ b/scripts/sys_schema/views/p_s/schema_table_statistics_with_buffer.sql @@ -49,7 +49,10 @@ -- innodb_buffer_bytes_data: 1924 -- innodb_buffer_rows_cached: 2 -- - + +DELIMITER $$ +BEGIN NOT ATOMIC +DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN END; CREATE OR REPLACE ALGORITHM = TEMPTABLE DEFINER = 'root'@'localhost' @@ -114,3 +117,6 @@ SELECT pst.object_schema AS table_schema, ON pst.object_schema = ibp.object_schema AND pst.object_name = ibp.object_name ORDER BY pst.sum_timer_wait DESC; + +END$$ +DELIMITER ; diff --git a/scripts/sys_schema/views/p_s/x_schema_table_statistics_with_buffer.sql b/scripts/sys_schema/views/p_s/x_schema_table_statistics_with_buffer.sql index 9f7c1dc580a..e9b48f390a8 100644 --- a/scripts/sys_schema/views/p_s/x_schema_table_statistics_with_buffer.sql +++ b/scripts/sys_schema/views/p_s/x_schema_table_statistics_with_buffer.sql @@ -49,7 +49,11 @@ -- innodb_buffer_pages_old: 42 -- innodb_buffer_rows_cached: 210 -- - + +DELIMITER $$ +BEGIN NOT ATOMIC +DECLARE EXIT HANDLER FOR SQLEXCEPTION BEGIN END; + CREATE OR REPLACE ALGORITHM = TEMPTABLE DEFINER = 'root'@'localhost' @@ -114,3 +118,5 @@ SELECT pst.object_schema AS table_schema, ON pst.object_schema = ibp.object_schema AND pst.object_name = ibp.object_name ORDER BY pst.sum_timer_wait DESC; +END$$ +DELIMITER ;