Skip to content
This repository was archived by the owner on Aug 28, 2024. It is now read-only.

Commit 76b512c

Browse files
Bug #23621189 PS_TRACE_STATEMENT_DIGEST FAILS AT EXPLAIN OR NO FOUND QUERIES
The ps_trace_statement_digest() procedure did not handle some conditions: * Queries (such as SHOW) that does not support EXPLAIN * Queries where one or more tables is not fully qualified as the table cannot be found when attempting to EXPLAIN it * When no queries with the specified digest is found during the monitored period These issues have been fixed and a new test case, sysschema.pr_ps_trace_statement_digest, has been added.
1 parent 4d505f1 commit 76b512c

File tree

4 files changed

+142
-14
lines changed

4 files changed

+142
-14
lines changed

README.md

Lines changed: 7 additions & 1 deletion
Original file line numberDiff line numberDiff line change
@@ -5024,7 +5024,13 @@ When finding a statement of interest within the performance_schema.events_statem
50245024

50255025
It will also attempt to generate an EXPLAIN for the longest running example of the digest during the interval.
50265026

5027-
Note this may fail, as Performance Schema truncates long SQL_TEXT values (and hence the EXPLAIN will fail due to parse errors).
5027+
Note this may fail, as:
5028+
5029+
* Performance Schema truncates long SQL_TEXT values (and hence the EXPLAIN will fail due to parse errors)
5030+
* the default schema is sys (so tables that are not fully qualified in the query may not be found)
5031+
* some queries such as SHOW are not supported in EXPLAIN.
5032+
5033+
When the EXPLAIN fails, the error will be ignored and no EXPLAIN output generated.
50285034

50295035
Requires the SUPER privilege for "SET sql_log_bin = 0;".
50305036

Lines changed: 30 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,30 @@
1+
use test;
2+
SET @threadid = sys.ps_thread_id(NULL);
3+
CREATE TABLE t1 (id INT PRIMARY KEY, val int);
4+
INSERT INTO test.t1 VALUES (1, 9);
5+
SET @digest.insert = (SELECT DIGEST FROM performance_schema.events_statements_history WHERE THREAD_ID = @threadid AND SQL_TEXT LIKE 'INSERT INTO test.t1 VALUES (1, 9)');
6+
SELECT * FROM t1;
7+
id val
8+
1 9
9+
SET @digest.select = (SELECT DIGEST FROM performance_schema.events_statements_history WHERE THREAD_ID = @threadid AND SQL_TEXT LIKE 'SELECT * FROM t1');
10+
SHOW CREATE TABLE test.t1;
11+
Table Create Table
12+
t1 CREATE TABLE `t1` (
13+
`id` int(11) NOT NULL,
14+
`val` int(11) DEFAULT NULL,
15+
PRIMARY KEY (`id`)
16+
) ENGINE=InnoDB DEFAULT CHARSET=latin1
17+
SET @digest.show = (SELECT DIGEST FROM performance_schema.events_statements_history WHERE THREAD_ID = @threadid AND SQL_TEXT LIKE 'SHOW CREATE TABLE test.t1');
18+
CREATE SCHEMA test_sys;
19+
use test_sys;
20+
CALL sys.ps_trace_statement_digest(@digest.insert, 0.5, 0.1, FALSE, FALSE);
21+
CALL sys.ps_trace_statement_digest(@digest.select, 0.5, 0.1, FALSE, FALSE);
22+
CALL sys.ps_trace_statement_digest(@digest.show , 0.5, 0.1, FALSE, FALSE);
23+
CALL sys.ps_trace_statement_digest(@digest.insert, 0.5, 0.1, TRUE , FALSE);
24+
use test;
25+
DROP SCHEMA test_sys;
26+
DROP TABLE t1;
27+
SET @threadid = NULL,
28+
@digest.insert = NULL,
29+
@digest.select = NULL,
30+
@digest.show = NULL;
Lines changed: 65 additions & 0 deletions
Original file line numberDiff line numberDiff line change
@@ -0,0 +1,65 @@
1+
########### suite/sysschema/t/pr_ps_trace_statement_digest.test #############
2+
# #
3+
# Testing of of the sys.ps_trace_statement_digest() procedure #
4+
# #
5+
# Creation: #
6+
# 2016-06-21 jkrogh Implement this test as part of #
7+
# Bug 23621189 PS_TRACE_STATEMENT_DIGEST FAILS AT EXPLAIN #
8+
# #
9+
#############################################################################
10+
11+
-- source include/not_embedded.inc
12+
# The ps_trace_statement_digest does not work with prepared statements
13+
# So disable this test with --ps-protocol
14+
-- source include/no_protocol.inc
15+
16+
use test;
17+
18+
# Get the thread id of this thread
19+
# Store it in a user variable as otherwise repeated calls to sys.ps_thread_id()
20+
# will keep changing performance_schema.events_statements_history
21+
SET @threadid = sys.ps_thread_id(NULL);
22+
23+
# Create a table
24+
CREATE TABLE t1 (id INT PRIMARY KEY, val int);
25+
26+
# Get digest of an INSERT statement with a qualified table name
27+
INSERT INTO test.t1 VALUES (1, 9);
28+
SET @digest.insert = (SELECT DIGEST FROM performance_schema.events_statements_history WHERE THREAD_ID = @threadid AND SQL_TEXT LIKE 'INSERT INTO test.t1 VALUES (1, 9)');
29+
30+
# Get digest of an SELECT statement using the default schema
31+
SELECT * FROM t1;
32+
SET @digest.select = (SELECT DIGEST FROM performance_schema.events_statements_history WHERE THREAD_ID = @threadid AND SQL_TEXT LIKE 'SELECT * FROM t1');
33+
34+
# Get digets of a SHOW statement (doesn't support EXPLAIN)
35+
SHOW CREATE TABLE test.t1;
36+
SET @digest.show = (SELECT DIGEST FROM performance_schema.events_statements_history WHERE THREAD_ID = @threadid AND SQL_TEXT LIKE 'SHOW CREATE TABLE test.t1');
37+
38+
# Don't execute ps_trace_statement_digest() in the same schema as the queries
39+
# to monitor - to ensure we handle queries using the default schema.
40+
CREATE SCHEMA test_sys;
41+
use test_sys;
42+
43+
# Only do sanity checks - no error should occur, but the actual output is non-deterministic
44+
--disable_result_log
45+
# Regular EXPLAINable SELECT with a qualified table name
46+
CALL sys.ps_trace_statement_digest(@digest.insert, 0.5, 0.1, FALSE, FALSE);
47+
# Table in query is not qualified and is not in the current default schema
48+
CALL sys.ps_trace_statement_digest(@digest.select, 0.5, 0.1, FALSE, FALSE);
49+
# SHOW queries doesn't work with EXPLAIN
50+
CALL sys.ps_trace_statement_digest(@digest.show , 0.5, 0.1, FALSE, FALSE);
51+
# Test that finding no queries works - the TRUE argument resets the P_S tables
52+
# used in ps_trace_statement_digest()
53+
CALL sys.ps_trace_statement_digest(@digest.insert, 0.5, 0.1, TRUE , FALSE);
54+
--enable_result_log
55+
56+
57+
58+
# Clean up
59+
use test;
60+
DROP SCHEMA test_sys;
61+
DROP TABLE t1;
62+
SET @threadid = NULL,
63+
@digest.insert = NULL,
64+
@digest.select = NULL,
65+
@digest.show = NULL;

procedures/ps_trace_statement_digest.sql

Lines changed: 40 additions & 13 deletions
Original file line numberDiff line numberDiff line change
@@ -1,4 +1,4 @@
1-
-- Copyright (c) 2014, 2015, Oracle and/or its affiliates. All rights reserved.
1+
-- Copyright (c) 2014, 2016, Oracle and/or its affiliates. All rights reserved.
22
--
33
-- This program is free software; you can redistribute it and/or modify
44
-- it under the terms of the GNU General Public License as published by
@@ -39,9 +39,16 @@ CREATE DEFINER='root'@'localhost' PROCEDURE ps_trace_statement_digest (
3939
interval.
4040
4141
It will also attempt to generate an EXPLAIN for the longest running
42-
example of the digest during the interval. Note this may fail, as
43-
Performance Schema truncates long SQL_TEXT values (and hence the
44-
EXPLAIN will fail due to parse errors).
42+
example of the digest during the interval. Note this may fail, as:
43+
44+
* Performance Schema truncates long SQL_TEXT values (and hence the
45+
EXPLAIN will fail due to parse errors)
46+
* the default schema is sys (so tables that are not fully qualified
47+
in the query may not be found)
48+
* some queries such as SHOW are not supported in EXPLAIN.
49+
50+
When the EXPLAIN fails, the error will be ignored and no EXPLAIN
51+
output generated.
4552
4653
Requires the SUPER privilege for "SET sql_log_bin = 0;".
4754
@@ -143,6 +150,7 @@ BEGIN
143150

144151
DECLARE v_start_fresh BOOLEAN DEFAULT false;
145152
DECLARE v_auto_enable BOOLEAN DEFAULT false;
153+
DECLARE v_explain BOOLEAN DEFAULT true;
146154
DECLARE v_this_thread_enabed ENUM('YES', 'NO');
147155
DECLARE v_runtime INT DEFAULT 0;
148156
DECLARE v_start INT DEFAULT 0;
@@ -269,19 +277,38 @@ BEGIN
269277
FROM stmt_trace
270278
ORDER BY timer_wait DESC LIMIT 1;
271279

272-
SELECT event_name,
273-
sys.format_time(timer_wait) as latency
274-
FROM stmt_stages
275-
WHERE stmt_id = @sql_id
276-
ORDER BY event_id;
280+
IF (@sql_id IS NOT NULL) THEN
281+
SELECT event_name,
282+
sys.format_time(timer_wait) as latency
283+
FROM stmt_stages
284+
WHERE stmt_id = @sql_id
285+
ORDER BY event_id;
286+
END IF;
277287

278288
DROP TEMPORARY TABLE stmt_trace;
279289
DROP TEMPORARY TABLE stmt_stages;
280290

281-
SET @stmt := CONCAT("EXPLAIN FORMAT=JSON ", @sql);
282-
PREPARE explain_stmt FROM @stmt;
283-
EXECUTE explain_stmt;
284-
DEALLOCATE PREPARE explain_stmt;
291+
IF (@sql IS NOT NULL) THEN
292+
SET @stmt := CONCAT("EXPLAIN FORMAT=JSON ", @sql);
293+
BEGIN
294+
-- Not all queries support EXPLAIN, so catch the cases that are
295+
-- not supported. Currently that includes cases where the table
296+
-- is not fully qualified and is not in the default schema for this
297+
-- procedure as it's not possible to change the default schema inside
298+
-- a procedure.
299+
--
300+
-- Errno = 1064: You have an error in your SQL syntax
301+
-- Errno = 1146: Table '...' doesn't exist
302+
DECLARE CONTINUE HANDLER FOR 1064, 1146 SET v_explain = false;
303+
304+
PREPARE explain_stmt FROM @stmt;
305+
END;
306+
307+
IF (v_explain) THEN
308+
EXECUTE explain_stmt;
309+
DEALLOCATE PREPARE explain_stmt;
310+
END IF;
311+
END IF;
285312

286313
IF v_auto_enable THEN
287314
CALL sys.ps_setup_reload_saved();

0 commit comments

Comments
 (0)