diff --git a/deps/oblib/src/lib/ash/ob_active_session_guard.h b/deps/oblib/src/lib/ash/ob_active_session_guard.h index 56d88682e8..50a8c097b5 100644 --- a/deps/oblib/src/lib/ash/ob_active_session_guard.h +++ b/deps/oblib/src/lib/ash/ob_active_session_guard.h @@ -31,6 +31,7 @@ public: tenant_id_(0), user_id_(0), session_id_(0), + plan_id_(0), sample_time_(0), event_no_(0), wait_time_(0), @@ -75,6 +76,7 @@ public: uint64_t tenant_id_; uint64_t user_id_; uint64_t session_id_; + uint64_t plan_id_; int64_t sample_time_; // sample time int64_t event_no_; // wait event no uint64_t wait_time_; // how long the event waited in total diff --git a/src/observer/virtual_table/ob_virtual_ash.cpp b/src/observer/virtual_table/ob_virtual_ash.cpp index 48f2408dd6..bb94003f70 100644 --- a/src/observer/virtual_table/ob_virtual_ash.cpp +++ b/src/observer/virtual_table/ob_virtual_ash.cpp @@ -241,6 +241,10 @@ int ObVirtualASH::convert_node_to_row(const ActiveSessionStat &node, ObNewRow *& #endif break; } + case PLAN_ID: { + cells[cell_idx].set_int(node.plan_id_); + break; + } default: { ret = OB_ERR_UNEXPECTED; SERVER_LOG(WARN, "invalid column id", K(column_id), K(cell_idx), diff --git a/src/observer/virtual_table/ob_virtual_ash.h b/src/observer/virtual_table/ob_virtual_ash.h index f818aba508..9e78cf39f4 100644 --- a/src/observer/virtual_table/ob_virtual_ash.h +++ b/src/observer/virtual_table/ob_virtual_ash.h @@ -67,7 +67,8 @@ private: MODULE, ACTION, CLIENT_ID, - BACKTRACE + BACKTRACE, + PLAN_ID }; DISALLOW_COPY_AND_ASSIGN(ObVirtualASH); share::ObActiveSessHistList::Iterator iterator_; diff --git a/src/share/ash/ob_active_sess_hist_task.cpp b/src/share/ash/ob_active_sess_hist_task.cpp index 06eb9a368a..79ee93114e 100644 --- a/src/share/ash/ob_active_sess_hist_task.cpp +++ b/src/share/ash/ob_active_sess_hist_task.cpp @@ -90,6 +90,7 @@ bool ObActiveSessHistTask::operator()(sql::ObSQLSessionMgr::Key key, ObSQLSessio stat.tenant_id_ = sess_info->get_effective_tenant_id(); stat.user_id_ = sess_info->get_user_id(); stat.session_id_ = sess_info->get_sessid(); + stat.plan_id_ = sess_info->get_current_plan_id(); stat.trace_id_ = sess_info->get_current_trace_id(); sess_info->get_cur_sql_id(stat.sql_id_, sizeof(stat.sql_id_)); ObActiveSessHistList::get_instance().add(stat); diff --git a/src/share/inner_table/ob_inner_table_schema.12301_12350.cpp b/src/share/inner_table/ob_inner_table_schema.12301_12350.cpp index 219b55f666..f74c3e7454 100644 --- a/src/share/inner_table/ob_inner_table_schema.12301_12350.cpp +++ b/src/share/inner_table/ob_inner_table_schema.12301_12350.cpp @@ -969,6 +969,21 @@ int ObInnerTableSchema::all_virtual_ash_schema(ObTableSchema &table_schema) true, //is_nullable false); //is_autoincrement } + + if (OB_SUCC(ret)) { + ADD_COLUMN_SCHEMA("PLAN_ID", //column_name + ++column_id, //column_id + 0, //rowkey_id + 0, //index_id + 0, //part_key_pos + ObIntType, //column_type + CS_TYPE_INVALID, //column_collation_type + sizeof(int64_t), //column_length + -1, //column_precision + -1, //column_scale + false, //is_nullable + false); //is_autoincrement + } if (OB_SUCC(ret)) { table_schema.get_part_option().set_part_num(1); table_schema.set_part_level(PARTITION_LEVEL_ONE); diff --git a/src/share/inner_table/ob_inner_table_schema.15201_15250.cpp b/src/share/inner_table/ob_inner_table_schema.15201_15250.cpp index 9f70d38d23..3ae7b890a6 100644 --- a/src/share/inner_table/ob_inner_table_schema.15201_15250.cpp +++ b/src/share/inner_table/ob_inner_table_schema.15201_15250.cpp @@ -12801,6 +12801,21 @@ int ObInnerTableSchema::all_virtual_ash_ora_schema(ObTableSchema &table_schema) true, //is_nullable false); //is_autoincrement } + + if (OB_SUCC(ret)) { + ADD_COLUMN_SCHEMA("PLAN_ID", //column_name + ++column_id, //column_id + 0, //rowkey_id + 0, //index_id + 0, //part_key_pos + ObNumberType, //column_type + CS_TYPE_INVALID, //column_collation_type + 38, //column_length + 38, //column_precision + 0, //column_scale + false, //is_nullable + false); //is_autoincrement + } if (OB_SUCC(ret)) { table_schema.get_part_option().set_part_num(1); table_schema.set_part_level(PARTITION_LEVEL_ONE); diff --git a/src/share/inner_table/ob_inner_table_schema.21251_21300.cpp b/src/share/inner_table/ob_inner_table_schema.21251_21300.cpp index f0c3e428c1..64ea22781e 100644 --- a/src/share/inner_table/ob_inner_table_schema.21251_21300.cpp +++ b/src/share/inner_table/ob_inner_table_schema.21251_21300.cpp @@ -909,7 +909,7 @@ int ObInnerTableSchema::gv_active_session_history_schema(ObTableSchema &table_sc table_schema.set_collation_type(ObCharset::get_default_collation(ObCharset::get_default_charset())); if (OB_SUCC(ret)) { - if (OB_FAIL(table_schema.set_view_definition(R"__(SELECT CAST(SVR_IP AS CHAR(46)) AS SVR_IP, CAST(SVR_PORT AS SIGNED) AS SVR_PORT, CAST(SAMPLE_ID AS SIGNED) AS SAMPLE_ID, CAST(SAMPLE_TIME AS DATETIME) AS SAMPLE_TIME, CAST(TENANT_ID AS SIGNED) AS CON_ID, CAST(USER_ID AS SIGNED) AS USER_ID, CAST(SESSION_ID AS SIGNED) AS SESSION_ID, CAST(IF (SESSION_TYPE = 0, 'FOREGROUND', 'BACKGROUND') AS CHAR(10)) AS SESSION_TYPE, CAST(IF (EVENT_NO = 0, 'ON CPU', 'WAITING') AS CHAR(7)) AS SESSION_STATE, CAST(SQL_ID AS CHAR(32)) AS SQL_ID, CAST(TRACE_ID AS CHAR(64)) AS TRACE_ID, CAST(NAME AS CHAR(64)) AS EVENT, CAST(EVENT_NO AS SIGNED) AS EVENT_NO, CAST(PARAMETER1 AS CHAR(64)) AS P1TEXT, CAST(P1 AS SIGNED) AS P1, CAST(PARAMETER2 AS CHAR(64)) AS P2TEXT, CAST(P2 AS SIGNED) AS P2, CAST(PARAMETER3 AS CHAR(64)) AS P3TEXT, CAST(P3 AS SIGNED) AS P3, CAST(WAIT_CLASS AS CHAR(64)) AS WAIT_CLASS, CAST(WAIT_CLASS_ID AS SIGNED) AS WAIT_CLASS_ID, CAST(TIME_WAITED AS SIGNED) AS TIME_WAITED, CAST(SQL_PLAN_LINE_ID AS SIGNED) SQL_PLAN_LINE_ID, CAST(IF (IN_PARSE = 1, 'Y', 'N') AS CHAR(1)) AS IN_PARSE, CAST(IF (IN_PL_PARSE = 1, 'Y', 'N') AS CHAR(1)) AS IN_PL_PARSE, CAST(IF (IN_PLAN_CACHE = 1, 'Y', 'N') AS CHAR(1)) AS IN_PLAN_CACHE, CAST(IF (IN_SQL_OPTIMIZE = 1, 'Y', 'N') AS CHAR(1)) AS IN_SQL_OPTIMIZE, CAST(IF (IN_SQL_EXECUTION = 1, 'Y', 'N') AS CHAR(1)) AS IN_SQL_EXECUTION, CAST(IF (IN_PX_EXECUTION = 1, 'Y', 'N') AS CHAR(1)) AS IN_PX_EXECUTION, CAST(IF (IN_SEQUENCE_LOAD = 1, 'Y', 'N') AS CHAR(1)) AS IN_SEQUENCE_LOAD, CAST(MODULE AS CHAR(64)) AS MODULE, CAST(ACTION AS CHAR(64)) AS ACTION, CAST(CLIENT_ID AS CHAR(64)) AS CLIENT_ID, CAST(BACKTRACE AS CHAR(512)) AS BACKTRACE FROM oceanbase.__all_virtual_ash LEFT JOIN oceanbase.v$event_name on EVENT_NO = `event#` )__"))) { + if (OB_FAIL(table_schema.set_view_definition(R"__(SELECT CAST(SVR_IP AS CHAR(46)) AS SVR_IP, CAST(SVR_PORT AS SIGNED) AS SVR_PORT, CAST(SAMPLE_ID AS SIGNED) AS SAMPLE_ID, CAST(SAMPLE_TIME AS DATETIME) AS SAMPLE_TIME, CAST(TENANT_ID AS SIGNED) AS CON_ID, CAST(USER_ID AS SIGNED) AS USER_ID, CAST(SESSION_ID AS SIGNED) AS SESSION_ID, CAST(IF (SESSION_TYPE = 0, 'FOREGROUND', 'BACKGROUND') AS CHAR(10)) AS SESSION_TYPE, CAST(IF (EVENT_NO = 0, 'ON CPU', 'WAITING') AS CHAR(7)) AS SESSION_STATE, CAST(SQL_ID AS CHAR(32)) AS SQL_ID, CAST(PLAN_ID AS SIGNED) AS PLAN_ID, CAST(TRACE_ID AS CHAR(64)) AS TRACE_ID, CAST(NAME AS CHAR(64)) AS EVENT, CAST(EVENT_NO AS SIGNED) AS EVENT_NO, CAST(PARAMETER1 AS CHAR(64)) AS P1TEXT, CAST(P1 AS SIGNED) AS P1, CAST(PARAMETER2 AS CHAR(64)) AS P2TEXT, CAST(P2 AS SIGNED) AS P2, CAST(PARAMETER3 AS CHAR(64)) AS P3TEXT, CAST(P3 AS SIGNED) AS P3, CAST(WAIT_CLASS AS CHAR(64)) AS WAIT_CLASS, CAST(WAIT_CLASS_ID AS SIGNED) AS WAIT_CLASS_ID, CAST(TIME_WAITED AS SIGNED) AS TIME_WAITED, CAST(SQL_PLAN_LINE_ID AS SIGNED) SQL_PLAN_LINE_ID, CAST(IF (IN_PARSE = 1, 'Y', 'N') AS CHAR(1)) AS IN_PARSE, CAST(IF (IN_PL_PARSE = 1, 'Y', 'N') AS CHAR(1)) AS IN_PL_PARSE, CAST(IF (IN_PLAN_CACHE = 1, 'Y', 'N') AS CHAR(1)) AS IN_PLAN_CACHE, CAST(IF (IN_SQL_OPTIMIZE = 1, 'Y', 'N') AS CHAR(1)) AS IN_SQL_OPTIMIZE, CAST(IF (IN_SQL_EXECUTION = 1, 'Y', 'N') AS CHAR(1)) AS IN_SQL_EXECUTION, CAST(IF (IN_PX_EXECUTION = 1, 'Y', 'N') AS CHAR(1)) AS IN_PX_EXECUTION, CAST(IF (IN_SEQUENCE_LOAD = 1, 'Y', 'N') AS CHAR(1)) AS IN_SEQUENCE_LOAD, CAST(MODULE AS CHAR(64)) AS MODULE, CAST(ACTION AS CHAR(64)) AS ACTION, CAST(CLIENT_ID AS CHAR(64)) AS CLIENT_ID, CAST(BACKTRACE AS CHAR(512)) AS BACKTRACE FROM oceanbase.__all_virtual_ash LEFT JOIN oceanbase.v$event_name on EVENT_NO = `event#` )__"))) { LOG_ERROR("fail to set view_definition", K(ret)); } } diff --git a/src/share/inner_table/ob_inner_table_schema.28101_28150.cpp b/src/share/inner_table/ob_inner_table_schema.28101_28150.cpp index a21e23d014..384d966b5f 100644 --- a/src/share/inner_table/ob_inner_table_schema.28101_28150.cpp +++ b/src/share/inner_table/ob_inner_table_schema.28101_28150.cpp @@ -2009,7 +2009,7 @@ int ObInnerTableSchema::gv_active_session_history_ora_schema(ObTableSchema &tabl table_schema.set_collation_type(ObCharset::get_default_collation(ObCharset::get_default_charset())); if (OB_SUCC(ret)) { - if (OB_FAIL(table_schema.set_view_definition(R"__(SELECT CAST(SVR_IP AS VARCHAR2(46)) AS SVR_IP, CAST(SVR_PORT AS NUMBER) AS SVR_PORT, CAST(SAMPLE_ID AS NUMBER) AS SAMPLE_ID, CAST(SAMPLE_TIME AS TIMESTAMP) AS SAMPLE_TIME, CAST(TENANT_ID AS NUMBER) AS CON_ID, CAST(USER_ID AS NUMBER) AS USER_ID, CAST(SESSION_ID AS NUMBER) AS SESSION_ID, CAST(DECODE(SESSION_TYPE, 0, 'FOREGROUND', 'BACKGROUND') AS VARCHAR2(10)) AS SESSION_TYPE, CAST(DECODE(EVENT_NO, 0, 'ON CPU', 'WAITING') AS VARCHAR2(7)) AS SESSION_STATE, CAST(SQL_ID AS VARCHAR(32)) AS SQL_ID, CAST(TRACE_ID AS VARCHAR(64)) AS TRACE_ID, CAST(NAME AS VARCHAR2(64)) AS EVENT, CAST(EVENT_NO AS NUMBER) AS EVENT_NO, CAST(PARAMETER1 AS VARCHAR2(64)) AS P1TEXT, CAST(P1 AS NUMBER) AS P1, CAST(PARAMETER2 AS VARCHAR2(64)) AS P2TEXT, CAST(P2 AS NUMBER) AS P2, CAST(PARAMETER3 AS VARCHAR2(64)) AS P3TEXT, CAST(P3 AS NUMBER) AS P3, CAST(WAIT_CLASS AS VARCHAR2(64)) AS WAIT_CLASS, CAST(WAIT_CLASS_ID AS NUMBER) AS WAIT_CLASS_ID, CAST(TIME_WAITED AS NUMBER) AS TIME_WAITED, CAST(SQL_PLAN_LINE_ID AS NUMBER) SQL_PLAN_LINE_ID, CAST(DECODE(IN_PARSE, 1, 'Y', 'N') AS VARCHAR2(1)) AS IN_PARSE, CAST(DECODE(IN_PL_PARSE, 1, 'Y', 'N') AS VARCHAR2(1)) AS IN_PL_PARSE, CAST(DECODE(IN_PLAN_CACHE, 1, 'Y', 'N') AS VARCHAR2(1)) AS IN_PLAN_CACHE, CAST(DECODE(IN_SQL_OPTIMIZE, 1, 'Y', 'N') AS VARCHAR2(1)) AS IN_SQL_OPTIMIZE, CAST(DECODE(IN_SQL_EXECUTION, 1, 'Y', 'N') AS VARCHAR2(1)) AS IN_SQL_EXECUTION, CAST(DECODE(IN_PX_EXECUTION, 1, 'Y', 'N') AS VARCHAR2(1)) AS IN_PX_EXECUTION, CAST(DECODE(IN_SEQUENCE_LOAD, 1, 'Y', 'N') AS VARCHAR2(1)) AS IN_SEQUENCE_LOAD, CAST(MODULE AS VARCHAR2(64)) AS MODULE, CAST(ACTION AS VARCHAR2(64)) AS ACTION, CAST(CLIENT_ID AS VARCHAR2(64)) AS CLIENT_ID, CAST(BACKTRACE AS VARCHAR2(512)) AS BACKTRACE FROM SYS.ALL_VIRTUAL_ASH LEFT JOIN SYS.V$EVENT_NAME on EVENT_NO = "EVENT#" )__"))) { + if (OB_FAIL(table_schema.set_view_definition(R"__(SELECT CAST(SVR_IP AS VARCHAR2(46)) AS SVR_IP, CAST(SVR_PORT AS NUMBER) AS SVR_PORT, CAST(SAMPLE_ID AS NUMBER) AS SAMPLE_ID, CAST(SAMPLE_TIME AS TIMESTAMP) AS SAMPLE_TIME, CAST(TENANT_ID AS NUMBER) AS CON_ID, CAST(USER_ID AS NUMBER) AS USER_ID, CAST(SESSION_ID AS NUMBER) AS SESSION_ID, CAST(DECODE(SESSION_TYPE, 0, 'FOREGROUND', 'BACKGROUND') AS VARCHAR2(10)) AS SESSION_TYPE, CAST(DECODE(EVENT_NO, 0, 'ON CPU', 'WAITING') AS VARCHAR2(7)) AS SESSION_STATE, CAST(SQL_ID AS VARCHAR(32)) AS SQL_ID, CAST(PLAN_ID AS NUMBER) AS PLAN_ID, CAST(TRACE_ID AS VARCHAR(64)) AS TRACE_ID, CAST(NAME AS VARCHAR2(64)) AS EVENT, CAST(EVENT_NO AS NUMBER) AS EVENT_NO, CAST(PARAMETER1 AS VARCHAR2(64)) AS P1TEXT, CAST(P1 AS NUMBER) AS P1, CAST(PARAMETER2 AS VARCHAR2(64)) AS P2TEXT, CAST(P2 AS NUMBER) AS P2, CAST(PARAMETER3 AS VARCHAR2(64)) AS P3TEXT, CAST(P3 AS NUMBER) AS P3, CAST(WAIT_CLASS AS VARCHAR2(64)) AS WAIT_CLASS, CAST(WAIT_CLASS_ID AS NUMBER) AS WAIT_CLASS_ID, CAST(TIME_WAITED AS NUMBER) AS TIME_WAITED, CAST(SQL_PLAN_LINE_ID AS NUMBER) SQL_PLAN_LINE_ID, CAST(DECODE(IN_PARSE, 1, 'Y', 'N') AS VARCHAR2(1)) AS IN_PARSE, CAST(DECODE(IN_PL_PARSE, 1, 'Y', 'N') AS VARCHAR2(1)) AS IN_PL_PARSE, CAST(DECODE(IN_PLAN_CACHE, 1, 'Y', 'N') AS VARCHAR2(1)) AS IN_PLAN_CACHE, CAST(DECODE(IN_SQL_OPTIMIZE, 1, 'Y', 'N') AS VARCHAR2(1)) AS IN_SQL_OPTIMIZE, CAST(DECODE(IN_SQL_EXECUTION, 1, 'Y', 'N') AS VARCHAR2(1)) AS IN_SQL_EXECUTION, CAST(DECODE(IN_PX_EXECUTION, 1, 'Y', 'N') AS VARCHAR2(1)) AS IN_PX_EXECUTION, CAST(DECODE(IN_SEQUENCE_LOAD, 1, 'Y', 'N') AS VARCHAR2(1)) AS IN_SEQUENCE_LOAD, CAST(MODULE AS VARCHAR2(64)) AS MODULE, CAST(ACTION AS VARCHAR2(64)) AS ACTION, CAST(CLIENT_ID AS VARCHAR2(64)) AS CLIENT_ID, CAST(BACKTRACE AS VARCHAR2(512)) AS BACKTRACE FROM SYS.ALL_VIRTUAL_ASH LEFT JOIN SYS.V$EVENT_NAME on EVENT_NO = "EVENT#" )__"))) { LOG_ERROR("fail to set view_definition", K(ret)); } } diff --git a/src/share/inner_table/ob_inner_table_schema_def.py b/src/share/inner_table/ob_inner_table_schema_def.py index 7a5c1c5742..331d1f8f91 100644 --- a/src/share/inner_table/ob_inner_table_schema_def.py +++ b/src/share/inner_table/ob_inner_table_schema_def.py @@ -10382,7 +10382,8 @@ def_table_schema( ('MODULE', 'varchar:64', 'true'), ('ACTION', 'varchar:64', 'true'), ('CLIENT_ID', 'varchar:64', 'true'), - ('BACKTRACE', 'varchar:512', 'true') + ('BACKTRACE', 'varchar:512', 'true'), + ('PLAN_ID', 'int') ], partition_columns = ['SVR_IP', 'SVR_PORT'], vtable_route_policy = 'distributed', @@ -20790,6 +20791,7 @@ def_table_schema( CAST(IF (SESSION_TYPE = 0, 'FOREGROUND', 'BACKGROUND') AS CHAR(10)) AS SESSION_TYPE, CAST(IF (EVENT_NO = 0, 'ON CPU', 'WAITING') AS CHAR(7)) AS SESSION_STATE, CAST(SQL_ID AS CHAR(32)) AS SQL_ID, + CAST(PLAN_ID AS SIGNED) AS PLAN_ID, CAST(TRACE_ID AS CHAR(64)) AS TRACE_ID, CAST(NAME AS CHAR(64)) AS EVENT, CAST(EVENT_NO AS SIGNED) AS EVENT_NO, @@ -44239,6 +44241,7 @@ def_table_schema( CAST(DECODE(SESSION_TYPE, 0, 'FOREGROUND', 'BACKGROUND') AS VARCHAR2(10)) AS SESSION_TYPE, CAST(DECODE(EVENT_NO, 0, 'ON CPU', 'WAITING') AS VARCHAR2(7)) AS SESSION_STATE, CAST(SQL_ID AS VARCHAR(32)) AS SQL_ID, + CAST(PLAN_ID AS NUMBER) AS PLAN_ID, CAST(TRACE_ID AS VARCHAR(64)) AS TRACE_ID, CAST(NAME AS VARCHAR2(64)) AS EVENT, CAST(EVENT_NO AS NUMBER) AS EVENT_NO, diff --git a/src/share/inner_table/sys_package/dbms_ash_internal.sql b/src/share/inner_table/sys_package/dbms_ash_internal.sql new file mode 100644 index 0000000000..e6c078578c --- /dev/null +++ b/src/share/inner_table/sys_package/dbms_ash_internal.sql @@ -0,0 +1,13 @@ +-- package_name:dbms_ash_internal +-- author:xiaochu.yh + + +CREATE OR REPLACE PACKAGE dbms_ash_internal AUTHID CURRENT_USER AS + + FUNCTION IN_MEMORY_ASH_VIEW_SQL + RETURN VARCHAR2; + + FUNCTION ASH_VIEW_SQL + RETURN VARCHAR2; + +END dbms_ash_internal; diff --git a/src/share/inner_table/sys_package/dbms_ash_internal_body.sql b/src/share/inner_table/sys_package/dbms_ash_internal_body.sql new file mode 100644 index 0000000000..df236c5c70 --- /dev/null +++ b/src/share/inner_table/sys_package/dbms_ash_internal_body.sql @@ -0,0 +1,69 @@ +-- package_name:dbms_ash_internal +-- author:xiaochu.yh + +CREATE OR REPLACE PACKAGE BODY dbms_ash_internal AS + + FUNCTION IN_MEMORY_ASH_VIEW_SQL + RETURN VARCHAR2 + IS + RETVAL VARCHAR2(30000); + BEGIN + RETVAL := 'SELECT a.sample_id, a.sample_time, ' || + ' a.svr_ip, ' || + ' a.svr_port, ' || + ' a.con_id, ' || + ' a.user_id, ' || + ' a.session_id, ' || + ' a.session_type, ' || + ' a.session_state, ' || + ' a.sql_id, ' || + ' plan_id, ' || + ' a.trace_id, ' || + ' nvl(a.event, ''CPU + Wait for CPU'') as event, ' || + ' nvl(a.event_no, 1) as event_no, ' || + ' a.p1, a.p1text, ' || + ' a.p2, a.p2text, ' || + ' a.p3, a.p3text, ' || + ' nvl(a.wait_class, ''CPU'') as wait_class, ' || + ' nvl(a.wait_class_id, 9999) as wait_class_id, ' || + ' a.time_waited, ' || + ' a.sql_plan_line_id, ' || + ' a.in_parse, ' || + ' a.in_pl_parse, ' || + ' a.in_plan_cache, ' || + ' a.in_sql_optimize, ' || + ' a.in_sql_execution, ' || + ' a.in_px_execution, ' || + ' a.in_sequence_load, ' || + ' a.module, a.action, a.client_id ' || + 'FROM GV$ACTIVE_SESSION_HISTORY a ' || + 'WHERE 1=1 '; + RETURN RETVAL; + END IN_MEMORY_ASH_VIEW_SQL; + + FUNCTION ASH_VIEW_SQL + RETURN VARCHAR2 + IS + RETVAL VARCHAR2(30000); + BEGIN + RETVAL := 'SELECT * FROM (' || IN_MEMORY_ASH_VIEW_SQL || + ' and a.sample_time between :ash_mem_btime and :ash_mem_etime ' || + ' ) unified_ash ' || + 'WHERE sample_time between :ash_begin_time ' || + ' and :ash_end_time ' || + ' AND (:ash_sql_id IS NULL ' || + ' OR sql_id like :ash_sql_id) ' || + ' AND (:ash_trace_id IS NULL ' || + ' OR trace_id like :ash_trace_id) ' || + ' AND (:ash_wait_class IS NULL ' || + ' OR wait_class like :ash_wait_class) ' || + ' AND (:ash_module IS NULL ' || + ' OR module like :ash_module) ' || + ' AND (:ash_action IS NULL ' || + ' OR action like :ash_action) ' || + ' AND (:ash_client_id IS NULL ' || + ' OR client_id like :ash_client_id)'; + RETURN RETVAL; + END ASH_VIEW_SQL; + +END dbms_ash_internal; diff --git a/src/share/inner_table/sys_package/dbms_workload_repository.sql b/src/share/inner_table/sys_package/dbms_workload_repository.sql new file mode 100644 index 0000000000..5036ad3eb0 --- /dev/null +++ b/src/share/inner_table/sys_package/dbms_workload_repository.sql @@ -0,0 +1,33 @@ +-- package_name:dbms_workload_repository +-- author:xiaochu.yh + + +-- +-- 完整 PL 包参考文档:https://docs.oracle.com/database/121/ARPLS/d_workload_repos.htm#ARPLS093 +-- +CREATE OR REPLACE PACKAGE dbms_workload_repository AUTHID CURRENT_USER AS + + -- Type declare + -- SUBTYPE OUTPUT_TYPE IS VARCHAR2(4000 CHAR); + TYPE awrrpt_text_type_table IS TABLE OF VARCHAR2(4096 CHAR) INDEX BY BINARY_INTEGER; + RPT_ROWS awrrpt_text_type_table; + + + TYPE SEC_REC IS RECORD( + TITLE VARCHAR2(4000 CHAR), + TITLE_TYPE VARCHAR2(1 CHAR) + ); + + TYPE SEC_REC_TAB IS TABLE OF SEC_REC + INDEX BY BINARY_INTEGER; + + TEST_ROW SEC_REC_TAB; + + FUNCTION ash_report_text(l_btime IN DATE, + l_etime IN DATE, + l_sql_id IN VARCHAR2 DEFAULT NULL, + l_wait_class IN VARCHAR2 DEFAULT NULL + ) + RETURN awrrpt_text_type_table; + +END dbms_workload_repository; diff --git a/src/share/inner_table/sys_package/dbms_workload_repository_body.sql b/src/share/inner_table/sys_package/dbms_workload_repository_body.sql new file mode 100644 index 0000000000..131f0ad190 --- /dev/null +++ b/src/share/inner_table/sys_package/dbms_workload_repository_body.sql @@ -0,0 +1,591 @@ +--package_name:dbms_workload_repository +--author:xiaochu.yh + +CREATE OR REPLACE PACKAGE BODY dbms_workload_repository AS + +TYPE COLUMN_CONTENT_ARRAY IS VARRAY(20) OF VARCHAR2(4096); +TYPE COLUMN_WIDTH_ARRAY IS VARRAY(20) OF INTEGER; + +DIG_3_FM VARCHAR2(20) := 'FM999999990.000'; +DIG_2_FM VARCHAR2(20) := 'FM999999990.00'; + +-- helper functions +PROCEDURE APPEND_ROW(ROW IN VARCHAR2) +IS +BEGIN + RPT_ROWS(RPT_ROWS.COUNT) := ROW; +END APPEND_ROW; + +PROCEDURE REPORT_CLEANUP +IS +BEGIN + IF (RPT_ROWS.COUNT > 0) THEN + RPT_ROWS.DELETE; + END IF; +END REPORT_CLEANUP; + +FUNCTION FORMAT_ROW(column_content IN COLUMN_CONTENT_ARRAY, + column_width IN COLUMN_WIDTH_ARRAY, + pad IN VARCHAR2, + sep IN VARCHAR2) +RETURN VARCHAR2 +IS + RES VARCHAR2(4000 CHAR); +BEGIN + RES := ''; + FOR i IN 1 .. column_content.count LOOP + RES := RES || LPAD(column_content(i), column_width(i), pad) || sep; + END LOOP; + RETURN RES; +END FORMAT_ROW; + + +-- main function +FUNCTION ASH_REPORT_TEXT(l_btime IN DATE, + l_etime IN DATE, + l_sql_id IN VARCHAR2 DEFAULT NULL, + l_wait_class IN VARCHAR2 DEFAULT NULL + ) +RETURN awrrpt_text_type_table +IS + DYN_SQL VARCHAR2(15000); + NULL_NUM NUMBER := NULL; + NULL_CHAR VARCHAR2(10) := NULL; + + TYPE TopEventCursor IS REF CURSOR; + top_event_cv TopEventCursor; + + TYPE TopEventRecord IS RECORD ( + EVENT SYS.V$ACTIVE_SESSION_HISTORY.EVENT%TYPE, + WAIT_CLASS SYS.V$ACTIVE_SESSION_HISTORY.WAIT_CLASS%TYPE, + EVENT_CNT NUMBER + ); + top_event_rec TopEventRecord; + + TYPE TopEventPvalRecord IS RECORD ( + EVENT SYS.V$ACTIVE_SESSION_HISTORY.EVENT%TYPE, + EVENT_CNT NUMBER, + SAMPLE_CNT NUMBER, + P1 SYS.V$ACTIVE_SESSION_HISTORY.P1%TYPE, + P2 SYS.V$ACTIVE_SESSION_HISTORY.P2%TYPE, + P3 SYS.V$ACTIVE_SESSION_HISTORY.P3%TYPE, + P1TEXT SYS.V$ACTIVE_SESSION_HISTORY.P1TEXT%TYPE, + P2TEXT SYS.V$ACTIVE_SESSION_HISTORY.P2TEXT%TYPE, + P3TEXT SYS.V$ACTIVE_SESSION_HISTORY.P3TEXT%TYPE + ); + top_event_pval_rec TopEventPvalRecord; + + TYPE TopAppInfoRecord IS RECORD ( + MODULE SYS.V$ACTIVE_SESSION_HISTORY.MODULE%TYPE, + ACTION SYS.V$ACTIVE_SESSION_HISTORY.ACTION%TYPE, + SAMPLE_CNT NUMBER + ); + top_appinfo_rec TopAppInfoRecord; + + TYPE TopPhaseOfExecutionRecord IS RECORD ( + EXECUTION_PHASE VARCHAR2(40), + SAMPLE_CNT NUMBER + ); + top_phase_rec TopPhaseOfExecutionRecord; + + TYPE TopSQLRecord IS RECORD ( + SQL_ID SYS.V$ACTIVE_SESSION_HISTORY.SQL_ID%TYPE, + PLAN_ID NUMBER, + EVENT_CNT NUMBER, + EVENT SYS.V$ACTIVE_SESSION_HISTORY.EVENT%TYPE, + QUERY_SQL SYS.V$OB_PLAN_CACHE_PLAN_STAT.QUERY_SQL%TYPE + ); + top_sql_rec TopSQLRecord; + + TYPE CompleteSQLRecord IS RECORD ( + SQL_ID SYS.V$ACTIVE_SESSION_HISTORY.SQL_ID%TYPE, + QUERY_SQL SYS.V$OB_PLAN_CACHE_PLAN_STAT.QUERY_SQL%TYPE + ); + complete_sql_rec CompleteSQLRecord; + + + TYPE TopSessionRecord IS RECORD ( + SESSION_ID SYS.V$ACTIVE_SESSION_HISTORY.SESSION_ID%TYPE, + EVENT SYS.V$ACTIVE_SESSION_HISTORY.EVENT%TYPE, + EVENT_CNT NUMBER, + SAMPLE_CNT NUMBER, + USER_NAME SYS.ALL_USERS.USERNAME%TYPE + ); + top_sess_rec TopSessionRecord; + + TYPE TopLatchRecord IS RECORD ( + EVENT SYS.V$ACTIVE_SESSION_HISTORY.EVENT%TYPE, + SAMPLE_CNT NUMBER + ); + top_latch_rec TopLatchRecord; + + + + + column_content COLUMN_CONTENT_ARRAY; + column_widths COLUMN_WIDTH_ARRAY; + + ASH_END_TIME Date; + ASH_BEGIN_TIME Date; + DUR_ELAPSED Number; + NUM_SAMPLES Number; + NUM_EVENTS Number; -- One event may cross many samples + + FILTER_EVENT_STR CONSTANT VARCHAR2(100) := 'CASE WHEN wait_class_id = 100 OR TIME_WAITED != 0 THEN 1 ELSE 0 END'; +BEGIN + REPORT_CLEANUP(); + + DBMS_OUTPUT.PUT_LINE(''); + DBMS_OUTPUT.PUT_LINE('# ' || l_sql_id); + DBMS_OUTPUT.PUT_LINE(''); + + DYN_SQL := 'SELECT MIN(SAMPLE_TIME) ASH_BEGIN_TIME, MAX(SAMPLE_TIME) ASH_END_TIME, COUNT(1) NUM_SAMPLES, SUM(' || FILTER_EVENT_STR || ') NUM_EVENTS ' || + 'FROM (' || DBMS_ASH_INTERNAL.ASH_VIEW_SQL || ') top_event '; + EXECUTE IMMEDIATE DYN_SQL + INTO ASH_BEGIN_TIME, ASH_END_TIME, NUM_SAMPLES, NUM_EVENTS + USING L_BTIME, L_ETIME, + L_BTIME, L_ETIME, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR; + DUR_ELAPSED := (ASH_END_TIME - ASH_BEGIN_TIME) * 24 * 60 * 60; -- in seconds + IF DUR_ELAPSED <= 0 THEN + DUR_ELAPSED := 1; -- avoid zero division + END IF; + IF NUM_SAMPLES <= 0 THEN + NUM_SAMPLES := 1; + END IF; + IF NUM_EVENTS <= 0 THEN + NUM_EVENTS := 1; + END IF; + + APPEND_ROW('----'); + APPEND_ROW(' Sample Begin: ' || TO_CHAR(L_BTIME, 'yyyy-mm-dd HH24:MI:SS')); + APPEND_ROW(' Sample End: ' || TO_CHAR(L_ETIME, 'yyyy-mm-dd HH24:MI:SS')); + APPEND_ROW(' ----------'); + APPEND_ROW(' Analysis Begin Time: ' || TO_CHAR(ASH_BEGIN_TIME, 'yyyy-mm-dd HH24:MI:SS')); + APPEND_ROW(' Analysis End Time: ' || TO_CHAR(ASH_END_TIME, 'yyyy-mm-dd HH24:MI:SS')); + APPEND_ROW(' Elapsed Time: ' || TO_CHAR(DUR_ELAPSED) || '(secs)'); + APPEND_ROW(' Num of Sample: ' || TO_CHAR(NUM_SAMPLES)); + APPEND_ROW(' Num of Events: ' || TO_CHAR(NUM_EVENTS)); + APPEND_ROW('Average Active Sessions: ' || TO_CHAR(ROUND(NUM_SAMPLES/DUR_ELAPSED,2), DIG_3_FM)); + APPEND_ROW('----'); + + APPEND_ROW(' '); + APPEND_ROW('## Top User Events:'); + column_widths := COLUMN_WIDTH_ARRAY(40, 20, 10, 9); + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + column_content := COLUMN_CONTENT_ARRAY('Event', 'WAIT_CLASS', 'EVENT_CNT', '% Event'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, ' ', '|')); + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + DYN_SQL := 'SELECT EVENT, WAIT_CLASS, COUNT(1) EVENT_CNT FROM (' || DBMS_ASH_INTERNAL.ASH_VIEW_SQL || ') top_event ' || 'GROUP BY EVENT, WAIT_CLASS'; + OPEN top_event_cv FOR DYN_SQL + USING L_BTIME, L_ETIME, + L_BTIME, L_ETIME, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR; + LOOP + FETCH top_event_cv INTO top_event_rec; + EXIT WHEN top_event_cv%NOTFOUND; + APPEND_ROW(FORMAT_ROW(COLUMN_CONTENT_ARRAY( + top_event_rec.EVENT, + top_event_rec.WAIT_CLASS, + TO_CHAR(top_event_rec.EVENT_CNT), + TO_CHAR(ROUND(100 * top_event_rec.EVENT_CNT/NUM_EVENTS,2), DIG_2_FM) || '%' + ), column_widths, ' ', '|')); + END LOOP; + CLOSE top_event_cv; + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + + + APPEND_ROW(' '); + APPEND_ROW('## Top Events P1/P2/P3 Value:'); + column_widths := COLUMN_WIDTH_ARRAY(40, 10, 12, 50, 20, 20, 20); + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-', '-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + column_content := COLUMN_CONTENT_ARRAY('Event', '% Event', '% Activity', 'Max P1/P2/P3', 'Parameter 1', 'Parameter 2', 'Parameter 3'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, ' ', '|')); + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-', '-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + DYN_SQL := 'SELECT * FROM (SELECT EVENT, SUM(' || FILTER_EVENT_STR || ') EVENT_CNT, COUNT(1) SAMPLE_CNT, MAX(P1) P1, MAX(P2) P2, MAX(P3) P3, MAX(P1TEXT) P1TEXT, MAX(P2TEXT) P2TEXT, MAX(P3TEXT) P3TEXT ' || + 'FROM (' || DBMS_ASH_INTERNAL.ASH_VIEW_SQL || ') top_event ' || + 'GROUP BY EVENT, WAIT_CLASS ORDER BY 2 DESC) WHERE ROWNUM < 10'; + OPEN top_event_cv FOR DYN_SQL + USING L_BTIME, L_ETIME, + L_BTIME, L_ETIME, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR; + LOOP + FETCH top_event_cv INTO top_event_pval_rec; + EXIT WHEN top_event_cv%NOTFOUND; + APPEND_ROW( + FORMAT_ROW( + COLUMN_CONTENT_ARRAY( + top_event_pval_rec.EVENT, + TO_CHAR(ROUND(100 * top_event_pval_rec.EVENT_CNT/NUM_EVENTS,2), DIG_2_FM) || '%', + TO_CHAR(ROUND(100 * top_event_pval_rec.SAMPLE_CNT/DUR_ELAPSED,3), DIG_3_FM) || '%', + '"' || TO_CHAR(top_event_pval_rec.P1) || '","' || TO_CHAR(top_event_pval_rec.P2) || '","' || TO_CHAR(top_event_pval_rec.P3) || '"', + NVL(top_event_pval_rec.P1TEXT, ' '), + NVL(top_event_pval_rec.P2TEXT, ' '), + NVL(top_event_pval_rec.P3TEXT, ' ') + ), + column_widths, ' ', '|' + ) + ); + END LOOP; + CLOSE top_event_cv; + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-', '-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + + + -- Not implemented yet + -- APPEND_ROW(' '); + -- APPEND_ROW('## Top Service/Module:'); + -- column_widths := COLUMN_WIDTH_ARRAY(40, 40, 12, 40, 12); + -- column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-', '-'); + -- APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + -- column_content := COLUMN_CONTENT_ARRAY('Service', 'Module', '% Activity', 'Action', '% Action'); + -- APPEND_ROW(FORMAT_ROW(column_content, column_widths, ' ', '|')); + -- column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-', '-'); + -- APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + -- DYN_SQL := 'SELECT * FROM (SELECT MODULE, ACTION, COUNT(1) SAMPLE_CNT ' || + -- 'FROM (' || DBMS_ASH_INTERNAL.ASH_VIEW_SQL || ') top_event ' || + -- 'GROUP BY MODULE, ROLLUP(ACTION) ORDER BY MODULE, SAMPLE_CNT DESC) ' || + -- 'WHERE SAMPLE_CNT / :num_samples_param > -0.01'; + -- OPEN top_event_cv FOR DYN_SQL + -- USING L_BTIME, L_ETIME, + -- L_BTIME, L_ETIME, + -- NULL_CHAR, NULL_CHAR, + -- NULL_CHAR, NULL_CHAR, + -- NULL_CHAR, NULL_CHAR, + -- NULL_CHAR, NULL_CHAR, + -- NULL_CHAR, NULL_CHAR, + -- NULL_CHAR, NULL_CHAR, + -- NUM_SAMPLES; + -- LOOP + -- FETCH top_event_cv INTO top_appinfo_rec; + -- EXIT WHEN top_event_cv%NOTFOUND; + -- APPEND_ROW( + -- FORMAT_ROW( + -- COLUMN_CONTENT_ARRAY( + -- '*', + -- NVL(top_appinfo_rec.MODULE, ' '), + -- TO_CHAR(ROUND(100 * top_appinfo_rec.SAMPLE_CNT/DUR_ELAPSED, 3), DIG_3_FM) || '%', + -- NVL(top_appinfo_rec.ACTION, ' '), + -- TO_CHAR(ROUND(100 * top_appinfo_rec.SAMPLE_CNT/NUM_SAMPLES,2), DIG_2_FM) || '%' + -- ), + -- column_widths, ' ', '|' + -- ) + -- ); + -- END LOOP; + -- CLOSE top_event_cv; + -- column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-', '-'); + -- APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + + + + APPEND_ROW(' '); + APPEND_ROW('## Top Phase of Execution:'); + column_widths := COLUMN_WIDTH_ARRAY(40, 12, 14, 40); + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + column_content := COLUMN_CONTENT_ARRAY('Phase of Execution', '% Activity', 'Sample Count', 'Avg Active Sessions'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, ' ', '|')); + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + DYN_SQL := 'SELECT * FROM (SELECT ' || + ' SUM(CASE IN_PARSE WHEN ''N'' THEN 0 ELSE 1 END) IN_PARSE, ' || + ' SUM(CASE IN_PL_PARSE WHEN ''N'' THEN 0 ELSE 1 END) IN_PL_PARSE, ' || + ' SUM(CASE IN_PLAN_CACHE WHEN ''N'' THEN 0 ELSE 1 END) IN_PLAN_CACHE, ' || + ' SUM(CASE IN_SQL_OPTIMIZE WHEN ''N'' THEN 0 ELSE 1 END) IN_SQL_OPTIMIZE, ' || + ' SUM(CASE IN_SQL_EXECUTION WHEN ''N'' THEN 0 ELSE 1 END) IN_SQL_EXECUTION, ' || + ' SUM(CASE IN_PX_EXECUTION WHEN ''N'' THEN 0 ELSE 1 END) IN_PX_EXECUTION, ' || + ' SUM(CASE IN_SEQUENCE_LOAD WHEN ''N'' THEN 0 ELSE 1 END) IN_SEQUENCE_LOAD ' || + 'FROM (' || DBMS_ASH_INTERNAL.ASH_VIEW_SQL || ') top_event ) phases ' || + ' unpivot ' || + ' (' || + ' SAMPLES_CNT FOR EXECUTION_PHASE IN (IN_PARSE, IN_PL_PARSE, IN_PLAN_CACHE, IN_SQL_OPTIMIZE, IN_SQL_EXECUTION,IN_PX_EXECUTION, IN_SEQUENCE_LOAD )' || + ' ) ORDER BY SAMPLES_CNT DESC'; + OPEN top_event_cv FOR DYN_SQL + USING L_BTIME, L_ETIME, + L_BTIME, L_ETIME, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR; + LOOP + FETCH top_event_cv INTO top_phase_rec; + EXIT WHEN top_event_cv%NOTFOUND; + APPEND_ROW( + FORMAT_ROW( + COLUMN_CONTENT_ARRAY( + top_phase_rec.EXECUTION_PHASE, + TO_CHAR(top_phase_rec.SAMPLE_CNT), + TO_CHAR(ROUND(100 * top_phase_rec.SAMPLE_CNT/NUM_SAMPLES, 3), DIG_3_FM) || '%', + TO_CHAR(ROUND(top_phase_rec.SAMPLE_CNT/DUR_ELAPSED,2), DIG_2_FM) + ), + column_widths, ' ', '|' + ) + ); + END LOOP; + CLOSE top_event_cv; + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + + + + APPEND_ROW(' '); + APPEND_ROW('## Top SQL with Top Events'); + APPEND_ROW(' - All events included.'); + APPEND_ROW(' - Empty ''SQL Text'' if it is PL/SQL query'); + column_widths := COLUMN_WIDTH_ARRAY(40, 12, 25, 40, 12, 60); + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + column_content := COLUMN_CONTENT_ARRAY('SQL ID', 'PLAN ID', 'Sampled # of Executions', 'Event', '% Event', 'SQL Text'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, ' ', '|')); + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + DYN_SQL := 'SELECT SQL_ID, PLAN_ID, EVENT_CNT, EVENT, QUERY_SQL FROM (SELECT ash.*, SUBSTR(TRIM(REPLACE(pc.QUERY_SQL, CHR(10), '''')), 0, 55) QUERY_SQL ' || + 'FROM (SELECT SQL_ID, PLAN_ID, SUM(' || FILTER_EVENT_STR || ') EVENT_CNT, EVENT FROM (' || + DBMS_ASH_INTERNAL.ASH_VIEW_SQL || + ') top_event GROUP BY SQL_ID, PLAN_ID, EVENT) ash ' || + 'LEFT JOIN SYS.GV$OB_PLAN_CACHE_PLAN_STAT pc ON ash.sql_id = pc.sql_id AND ash.plan_id = pc.plan_id ORDER BY EVENT_CNT DESC) v1 WHERE ROWNUM < 100'; + OPEN top_event_cv FOR DYN_SQL + USING L_BTIME, L_ETIME, + L_BTIME, L_ETIME, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR; + LOOP + FETCH top_event_cv INTO top_sql_rec; + EXIT WHEN top_event_cv%NOTFOUND; + APPEND_ROW(FORMAT_ROW(COLUMN_CONTENT_ARRAY( + top_sql_rec.SQL_ID, + TO_CHAR(top_sql_rec.PLAN_ID), + TO_CHAR(top_sql_rec.EVENT_CNT), + top_sql_rec.EVENT, + TO_CHAR(ROUND(100 * top_sql_rec.EVENT_CNT/NUM_EVENTS, 2), DIG_2_FM) || '%', + NVL(top_sql_rec.QUERY_SQL, ' ') + ), column_widths, ' ', '|')); + END LOOP; + CLOSE top_event_cv; + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + + + + + APPEND_ROW(' '); + APPEND_ROW('## Top SQL with Top Blocking Events'); + APPEND_ROW(' - Empty result if no event other than On CPU sampled'); + APPEND_ROW(' - Empty ''SQL Text'' if it is PL/SQL query'); + column_widths := COLUMN_WIDTH_ARRAY(40, 12, 25, 40, 12, 60); + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + column_content := COLUMN_CONTENT_ARRAY('SQL ID', 'PLAN ID', 'Sampled # of Executions', 'Event', '% Event', 'SQL Text'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, ' ', '|')); + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + DYN_SQL := 'SELECT SQL_ID, PLAN_ID, EVENT_CNT, EVENT, QUERY_SQL ' || + 'FROM (SELECT ash.*, SUBSTR(REPLACE(pc.QUERY_SQL, CHR(10), '' ''), 0, 55) QUERY_SQL ' || + ' FROM (SELECT SQL_ID, PLAN_ID, SUM(' || FILTER_EVENT_STR || ') EVENT_CNT, EVENT FROM (' || + DBMS_ASH_INTERNAL.ASH_VIEW_SQL || + ' ) top_event WHERE wait_class_id != 100 GROUP BY SQL_ID, PLAN_ID, EVENT) ash ' || + 'LEFT JOIN GV$OB_PLAN_CACHE_PLAN_STAT pc ON ash.sql_id = pc.sql_id AND ash.plan_id = pc.plan_id ORDER BY EVENT_CNT DESC) WHERE ROWNUM < 100'; + OPEN top_event_cv FOR DYN_SQL + USING L_BTIME, L_ETIME, + L_BTIME, L_ETIME, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR; + LOOP + FETCH top_event_cv INTO top_sql_rec; + EXIT WHEN top_event_cv%NOTFOUND; + APPEND_ROW(FORMAT_ROW(COLUMN_CONTENT_ARRAY( + top_sql_rec.SQL_ID, + TO_CHAR(top_sql_rec.PLAN_ID), + TO_CHAR(top_sql_rec.EVENT_CNT), + top_sql_rec.EVENT, + TO_CHAR(ROUND(100 * top_sql_rec.EVENT_CNT/NUM_EVENTS, 2), DIG_2_FM) || '%', + NVL(top_sql_rec.QUERY_SQL, ' ') + ), column_widths, ' ', '|')); + END LOOP; + CLOSE top_event_cv; + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + + -- complete List of SQL Text + APPEND_ROW(' '); + APPEND_ROW('## Complete List of SQL Text'); + DYN_SQL := 'SELECT SQL_ID, QUERY_SQL FROM (SELECT pc.SQL_ID SQL_ID, pc.QUERY_SQL QUERY_SQL ' || + 'FROM (SELECT SQL_ID, PLAN_ID, COUNT(1) EVENT_CNT FROM (' || DBMS_ASH_INTERNAL.ASH_VIEW_SQL || ') top_event GROUP BY SQL_ID, PLAN_ID, EVENT) ash ' || + 'LEFT JOIN GV$OB_PLAN_CACHE_PLAN_STAT pc ON ash.sql_id = pc.sql_id AND ash.plan_id = pc.plan_id ORDER BY EVENT_CNT DESC) WHERE QUERY_SQL IS NOT NULL AND ROWNUM < 100'; + OPEN top_event_cv FOR DYN_SQL + USING L_BTIME, L_ETIME, + L_BTIME, L_ETIME, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR; + LOOP + FETCH top_event_cv INTO complete_sql_rec; + EXIT WHEN top_event_cv%NOTFOUND; + APPEND_ROW(' SQL ID: ' || NVL(complete_sql_rec.SQL_ID, ' ')); + APPEND_ROW('SQL Text: ' || NVL(SUBSTR(complete_sql_rec.QUERY_SQL, 0, 4000), ' ')); + APPEND_ROW(''); + END LOOP; + CLOSE top_event_cv; + + + APPEND_ROW(' '); + APPEND_ROW('## Top Sessions:'); + APPEND_ROW(' - ''# Samples Active'' shows the number of ASH samples in which the session was found waiting for that particular event. The percentage shown in this column is calculated with respect to wall time.'); + column_widths := COLUMN_WIDTH_ARRAY(20, 22, 40, 12, 12, 20, '20'); + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-', '-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + column_content := COLUMN_CONTENT_ARRAY('Sid', '% Activity', 'Event', 'Event Count', '% Event', 'User', '# Samples Active'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, ' ', '|')); + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-', '-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + DYN_SQL := 'SELECT SESSION_ID, EVENT, EVENT_CNT, SAMPLE_CNT, USERNAME USER_NAME ' || + ' FROM (SELECT * FROM (SELECT SESSION_ID, USER_ID, EVENT, SUM(' || FILTER_EVENT_STR || ') EVENT_CNT, COUNT(1) SAMPLE_CNT FROM (' || DBMS_ASH_INTERNAL.ASH_VIEW_SQL || ') top_event ' || + ' GROUP BY SESSION_ID, USER_ID, EVENT HAVING COUNT(1) / :num_samples > 0.005 ORDER BY SAMPLE_CNT DESC) WHERE ROWNUM < 100) ash ' || + ' LEFT JOIN SYS.ALL_USERS u ON u.USERID = ash.USER_ID'; + OPEN top_event_cv FOR DYN_SQL + USING L_BTIME, L_ETIME, + L_BTIME, L_ETIME, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, NUM_SAMPLES; + LOOP + FETCH top_event_cv INTO top_sess_rec; + EXIT WHEN top_event_cv%NOTFOUND; + APPEND_ROW(FORMAT_ROW(COLUMN_CONTENT_ARRAY( + TO_CHAR(top_sess_rec.SESSION_ID), + TO_CHAR(ROUND(100 * top_sess_rec.SAMPLE_CNT/NUM_SAMPLES, 2), DIG_2_FM) || '%', + top_sess_rec.EVENT, + TO_CHAR(top_sess_rec.EVENT_CNT), + TO_CHAR(ROUND(100 * top_sess_rec.EVENT_CNT/NUM_EVENTS, 2), DIG_2_FM) || '%', + NVL(top_sess_rec.USER_NAME, ' '), + TO_CHAR(top_sess_rec.EVENT_CNT) || '/' || TO_CHAR(DUR_ELAPSED) || '[' || TO_CHAR(ROUND(100*top_sess_rec.EVENT_CNT/DUR_ELAPSED, 2), DIG_2_FM) || '%]' + ), column_widths, ' ', '|')); + END LOOP; + CLOSE top_event_cv; + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-', '-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + + + + + APPEND_ROW(' '); + APPEND_ROW('## Top Blocking Sessions:'); + APPEND_ROW(' - Blocking session activity percentages are calculated with respect to waits on latches and locks only.'); + APPEND_ROW(' - ''# Samples Active'' shows the number of ASH samples in which the blocking session was found active.'); + column_widths := COLUMN_WIDTH_ARRAY(20, 22, 40, 12, 12, 20, '20'); + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-', '-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + column_content := COLUMN_CONTENT_ARRAY('Blocking Sid', '% Activity', 'Event Caused', 'Event Count', '% Event', 'User', '# Samples Active'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, ' ', '|')); + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-', '-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + DYN_SQL := 'SELECT SESSION_ID, EVENT, EVENT_CNT, SAMPLE_CNT, USERNAME USER_NAME ' || + ' FROM (SELECT * FROM (SELECT SESSION_ID, USER_ID, EVENT, SUM(' || FILTER_EVENT_STR || ') EVENT_CNT, COUNT(1) SAMPLE_CNT FROM (' || DBMS_ASH_INTERNAL.ASH_VIEW_SQL || ') top_event ' || + ' WHERE wait_class_id != 100 GROUP BY SESSION_ID, USER_ID, EVENT HAVING COUNT(1) / :num_samples > 0.005 ORDER BY SAMPLE_CNT DESC) WHERE ROWNUM < 100) ash ' || + ' LEFT JOIN SYS.ALL_USERS u ON u.USERID = ash.USER_ID'; + OPEN top_event_cv FOR DYN_SQL + USING L_BTIME, L_ETIME, + L_BTIME, L_ETIME, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, NUM_SAMPLES; + LOOP + FETCH top_event_cv INTO top_sess_rec; + EXIT WHEN top_event_cv%NOTFOUND; + DBMS_OUTPUT.PUT_LINE(TO_CHAR(top_sess_rec.EVENT_CNT)); + APPEND_ROW(FORMAT_ROW(COLUMN_CONTENT_ARRAY( + TO_CHAR(top_sess_rec.SESSION_ID), + TO_CHAR(ROUND(100 * top_sess_rec.SAMPLE_CNT/NUM_SAMPLES, 2), DIG_2_FM) || '%', + top_sess_rec.EVENT, + TO_CHAR(top_sess_rec.EVENT_CNT), + TO_CHAR(ROUND(100 * top_sess_rec.EVENT_CNT/NUM_EVENTS, 2), DIG_2_FM) || '%', + top_sess_rec.USER_NAME, + TO_CHAR(top_sess_rec.EVENT_CNT) || '/' || TO_CHAR(DUR_ELAPSED) || '[' || TO_CHAR(ROUND(100*top_sess_rec.EVENT_CNT/DUR_ELAPSED, 2), DIG_2_FM) || '%]' + ), column_widths, ' ', '|')); + END LOOP; + CLOSE top_event_cv; + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-', '-', '-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + + + + APPEND_ROW(' '); + APPEND_ROW('## Top latches:'); + column_widths := COLUMN_WIDTH_ARRAY(40, 20, 20); + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + column_content := COLUMN_CONTENT_ARRAY('Latch', 'Sampled Count', '% Activity'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, ' ', '|')); + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + DYN_SQL := 'SELECT * FROM (SELECT EVENT, COUNT(1) SAMPLE_CNT FROM (' || DBMS_ASH_INTERNAL.ASH_VIEW_SQL || ') top_event ' || + ' WHERE wait_class_id = 104 AND SUBSTR(event, 0, 6) = ''latch:'' GROUP BY EVENT HAVING COUNT(1) / :num_samples > 0.005 ORDER BY SAMPLE_CNT DESC) WHERE ROWNUM < 100'; + OPEN top_event_cv FOR DYN_SQL + USING L_BTIME, L_ETIME, + L_BTIME, L_ETIME, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, + NULL_CHAR, NULL_CHAR, NUM_SAMPLES; + LOOP + FETCH top_event_cv INTO top_latch_rec; + EXIT WHEN top_event_cv%NOTFOUND; + APPEND_ROW(FORMAT_ROW(COLUMN_CONTENT_ARRAY( + TO_CHAR(top_latch_rec.EVENT), + TO_CHAR(top_latch_rec.SAMPLE_CNT), + TO_CHAR(ROUND(100 * top_latch_rec.SAMPLE_CNT/NUM_SAMPLES, 2), DIG_2_FM) || '%' + ), column_widths, ' ', '|')); + END LOOP; + CLOSE top_event_cv; + column_content := COLUMN_CONTENT_ARRAY('-', '-', '-'); + APPEND_ROW(FORMAT_ROW(column_content, column_widths, '-', '+')); + + + return RPT_ROWS; + +END ASH_REPORT_TEXT; + + + +END dbms_workload_repository; diff --git a/src/sql/engine/ob_physical_plan.cpp b/src/sql/engine/ob_physical_plan.cpp index dc2bd3eb58..e567c3bf2d 100644 --- a/src/sql/engine/ob_physical_plan.cpp +++ b/src/sql/engine/ob_physical_plan.cpp @@ -742,7 +742,8 @@ OB_SERIALIZE_MEMBER(ObPhysicalPlan, has_instead_of_trigger_, is_plain_insert_, ddl_execution_id_, - ddl_task_id_); + ddl_task_id_, + stat_.plan_id_); int ObPhysicalPlan::set_table_locations(const ObTablePartitionInfoArray &infos, ObSchemaGetterGuard &schema_guard) diff --git a/src/sql/session/ob_basic_session_info.cpp b/src/sql/session/ob_basic_session_info.cpp index d8c5a564d9..3b2ba756ff 100644 --- a/src/sql/session/ob_basic_session_info.cpp +++ b/src/sql/session/ob_basic_session_info.cpp @@ -104,6 +104,7 @@ ObBasicSessionInfo::ObBasicSessionInfo() next_tx_isolation_(transaction::ObTxIsolationLevel::INVALID), log_id_level_map_valid_(false), cur_phy_plan_(NULL), + plan_id_(0), capability_(), proxy_capability_(), client_mode_(OB_MIN_CLIENT_MODE), @@ -374,6 +375,7 @@ void ObBasicSessionInfo::reset(bool skip_sys_var) log_id_level_map_valid_ = false; log_id_level_map_.reset_level(); cur_phy_plan_ = NULL; + plan_id_ = 0; capability_.capability_ = 0; proxy_capability_.capability_ = 0; client_mode_ = OB_MIN_CLIENT_MODE; @@ -1927,6 +1929,7 @@ int ObBasicSessionInfo::sys_variable_exists(const ObString &var, bool &is_exists return ret; } +// for query and DML int ObBasicSessionInfo::set_cur_phy_plan(ObPhysicalPlan *cur_phy_plan) { int ret = OB_SUCCESS; @@ -1935,6 +1938,7 @@ int ObBasicSessionInfo::set_cur_phy_plan(ObPhysicalPlan *cur_phy_plan) LOG_WARN("current physical plan is NULL", K(lbt()), K(ret)); } else { cur_phy_plan_ = cur_phy_plan; + plan_id_ = cur_phy_plan->get_plan_id(); int64_t len = cur_phy_plan->stat_.sql_id_.length(); MEMCPY(sql_id_, cur_phy_plan->stat_.sql_id_.ptr(), len); sql_id_[len] = '\0'; @@ -1942,6 +1946,7 @@ int ObBasicSessionInfo::set_cur_phy_plan(ObPhysicalPlan *cur_phy_plan) return ret; } +// for cmd only void ObBasicSessionInfo::set_cur_sql_id(char *sql_id) { if (nullptr == sql_id) { diff --git a/src/sql/session/ob_basic_session_info.h b/src/sql/session/ob_basic_session_info.h index 0ec6c143ec..5f46454067 100644 --- a/src/sql/session/ob_basic_session_info.h +++ b/src/sql/session/ob_basic_session_info.h @@ -1120,6 +1120,7 @@ public: int64_t get_current_execution_id() const { return current_execution_id_; } const common::ObCurTraceId::TraceId &get_last_trace_id() const { return last_trace_id_; } const common::ObCurTraceId::TraceId &get_current_trace_id() const { return curr_trace_id_; } + uint64_t get_current_plan_id() const { return plan_id_; } void set_current_execution_id(int64_t execution_id) { current_execution_id_ = execution_id; } void set_last_trace_id(common::ObCurTraceId::TraceId *trace_id) { @@ -1931,6 +1932,7 @@ private: ObPhysicalPlan *cur_phy_plan_; // sql_id of cur_phy_plan_ sql char sql_id_[common::OB_MAX_SQL_ID_LENGTH + 1]; + uint64_t plan_id_; // for ASH sampling, get current SQL's sql_id & plan_id char flt_trace_id_[common::OB_MAX_UUID_LENGTH + 1]; char flt_span_id_[common::OB_MAX_UUID_LENGTH + 1];