You can call the Active Session History (ASH) PL package to generate an ASH report.
SQL syntax
The ASH PL package consists of the following parameters:
obclient [oceanbase]> call dbms_workload_repository.ash_report(
'BTIME',
'ETIME',
'SQL_ID',
'TRACE_ID',
'WAIT_CLASS',
'REPORT_TYPE',
'SVR_IP',
'SVR_PORT',
'TENANT_ID');
obclient [SYS]> call dbms_workload_repository.ash_report(
BTIME => 'xxxx',
ETIME => 'xxxx',
SQL_ID => 'xxxx',
TRACE_ID => 'xxxx',
WAIT_CLASS => 'xxxx',
REPORT_TYPE => 'xxxx',
SVR_IP => 'xxxx',
SVR_PORT=> 'xxxx',
TENANT_ID => 'xxxx');
The parameters are described as follows:
| Parameter | Description |
|---|---|
| BTIME | The start time of sampling. Required. |
| ETIME | The end time of sampling. Required. |
| SQL_ID | The SQL_ID of the SQL statement to sample. If this parameter is not specified or set to NULL, no restriction is applied to the SQL_ID. |
| TRACE_ID | The TRACE_ID of the SQL statement to sample. If this parameter is not specified or set to NULL, no restriction is applied to the TRACE_ID. |
| WAIT_CLASS | The event type to sample. Valid values are the same as those of the WAIT_CLASS field in the GV$OB_ACTIVE_SESSION_HISTORY view. If this parameter is not specified or set to NULL, no restriction is applied to the wait type. |
| REPORT_TYPE | The report type. Valid values include HTML and TEXT. If this parameter is not specified or set to NULL, the default value is TEXT. |
| SVR_IP | The IP address of the node to generate the ASH report. If this parameter is not specified or set to NULL, no restriction is applied to the SVR_IP. |
| SVR_PORT | The port of the node to generate the ASH report. If this parameter is not specified or set to NULL, no restriction is applied to the SVR_PORT. |
| TENANT_ID | The ID of the tenant to generate the ASH report. If this parameter is not specified or set to NULL, no restriction is applied to the TENANT_ID. |
Notice
- If you do not specify the SVR_IP, SVR_PORT, or TENANT_ID parameter, the following information will be collected:
- In the sys tenant, information about all IP addresses, ports, and tenants will be collected.
- In a user tenant, information about all IP addresses and ports in the tenant will be collected.
- In MySQL mode, if you explicitly specify a value for a non-required parameter, you must explicitly set the other non-required parameters to `NULL`. Otherwise, the parameters will be ignored.
You can query the GV$OB_ACTIVE_SESSION_HISTORY view to obtain information about the ASH PL package. The GV$OB_ACTIVE_SESSION_HISTORY view provides session activity information. Any session that is connected to the database and waiting in the queue is considered an active session. Each session is sampled by a set of rows returned by the GV$OB_ACTIVE_SESSION_HISTORY view, and each active session is displayed in the view during the sampling period. For more information about this view, see GV$OB_ACTIVE_SESSION_HISTORY (MySQL mode) and GV$OB_ACTIVE_SESSION_HISTORY (Oracle mode).
Procedure
To generate an ASH report, perform the following steps.
Log in to a MySQL tenant of the cluster as a tenant administrator and enter OceanBase Database.
$ obclient -h172.xx.xxx.xxx -Pxxxx -uroot@mysql -pxxxx -ADisplay the report information on the console.
Call the ASH PL package and specify the start and end times of the diagnostic period and the format for displaying the report.
Note
We recommend that you set the format to TEXT when you view the report on the console.
Display the report content on the console in TEXT format.
Set the diagnostic start time to
2024-02-22 19:26:47, the diagnostic end time to2024-06-22 19:27:07, and the report display format toTEXT. Set other parameters as needed.obclient [test]> CALL DBMS_WORKLOAD_REPOSITORY.ASH_REPORT( '2023-09-22 10:26:47', '2024-06-22 20:27:07', NULL, NULL, NULL, 'TEXT', NULL, NULL, NULL);Here is a portion of the generated report:
ASH Report Cluster Name: test424 Observer Version: OceanBase 4.2.4.0 (200000342024061210-c4c0c18741e45a1d40889b6147c3132574xxxxxx) Operation System Info: Linux(3.10.0-327.ali2019.alios7.x86_64)_x86_64 User Input Begin Time: 2023-09-22 10:26:47 User Input End Time: 2024-06-22 20:27:07 Analysis Begin Time: 2024-06-13 18:24:34 Analysis End Time: 2024-06-14 16:42:55 Elapsed Time: 80300 Num of Sample: 16433 Average Active Sessions: 0.20 Top Active Tenants: - this section lists top active tenant information - Total Count: num of records during ash report analysis time period - Wait Event Count: num of records when session is on wait event - On CPU Count: num of records when session is on cpu - Avg Active Sessions: average active sessions during ash report analysis time period - % Activity: activity(cpu + wait) percentage for given tenant +---------+------------+------------------+-----------------------+-------------------+--------------------+-----------+ |Tenant ID|Session Type| Total Count| Wait Event Count| On CPU Count| Avg Active Sessions| % Activity| +---------+------------+------------------+-----------------------+-------------------+--------------------+-----------+ | 1002| BACKGROUND| 16401| 1951| 14450| 0.20| 99.81%| | 1002| FOREGROUND| 32| 22| 10| 0.00| 0.20%| +---------+------------+------------------+-----------------------+-------------------+--------------------+-----------+Display the report content on the console in HTML format.
Set the diagnostic start time to
2024-02-22 19:26:47, the diagnostic end time to2024-06-22 19:27:07, and the report display format toHTML. Set other parameters as needed.obclient [test]>CALL DBMS_WORKLOAD_REPOSITORY.ASH_REPORT( '2023-09-22 10:26:47', '2024-06-22 20:27:07', NULL, NULL, NULL, 'HTML', NULL, NULL, NULL);Here is a portion of the generated report:
Observer Version: OceanBase 4.2.4.0 (200000342024061210-c4c0c18741e45a1d40889b6147c3132574xxxxxx) Operation System Info: Linux(3.10.0-327.ali2019.alios7.x86_64)_x86_64 User Input Begin Time: 2024-02-22 19:26:47 User Input End Time: 2024-06-22 19:27:07 Analysis Begin Time: 2024-06-13 18:24:34 Analysis End Time: 2024-06-14 17:04:21 Elapsed Time: 81586 Num of Sample: 16814 Average Active Sessions: 0.21 </pre><ul id=110></ul><a class="ash_html" name='Top Active Tenants'></a> <h2 class="ash_html">Top Active Tenants<br></h2><ul><li class='ash_html'>this section lists top active tenant information</li> <li class='ash_html'>Total Count: num of records during ash report analysis time period</li> <li class='ash_html'>Wait Event Count: num of records when session is on wait event</li> <li class='ash_html'>On CPU Count: num of records when session is on cpu</li> <li class='ash_html'>Avg Active Sessions: average active sessions during ash report analysis time period</li> <li class='ash_html'>% Activity: activity(cpu + wait) percentage for given tenant</li>
(Optional) View the report information on the local machine.
You can view the report information in TXT file or HTML page format. Here, we use the HTML page format as an example.
Log in to the physical server.
[admin@xxxxxx.eu95sqa /home/admin]Create an ASH report script file named
ash_report.htmlon the OBServer node.[admin@xxxxxx.eu95sqa /home/admin] $vim ash_report_my.htmlGenerate the script content.
tee ash_report_my.html CALL DBMS_WORKLOAD_REPOSITORY.ASH_REPORT( '2023-09-22 10:26:47', '2024-06-22 20:27:07', NULL, NULL, NULL, 'HTML', NULL, NULL, NULL); noteeLog in to the database and run the
ash_report_my.htmlscript.$ obclient -h172.xx.xxx.xxx -Pxxxx -uroot@mysql -pxxxx -Aobclient [test]> source ash_report_my.html;After the script is successfully executed, the HTML report content will be displayed on the console.
Exit the database and go to the physical server to find the
ash_report_my.htmlfile.[admin@k08j13249.eu95sqa /home/admin] $ls ALTER ash_report_my.htmlThe path of the
ash_report_my.htmlfile is found to behome/admin/ash_report_my.html.Export the file from the physical server to the local machine.
Open a new shell window and go to the directory where you want to save the file.
PS C:\Users\xxx\Desktop\ASH>Use the
scpcommand to import theash_report_my.htmlfile from the physical server to the local machine.scp admin@xx.xx.xx.xx:/home/admin/ash_report_my.html /Open the
ash_report_my.htmlfile in the local directory to view the report information.
Log in to an Oracle tenant of the cluster as the
SYSuser and enter OceanBase Database.$ obclient -h172.xx.xxx.xxx -Pxxxx -usys@oracle -pxxxx -AExecute the
SET SERVEROUTPUT ONstatement to enable the console to display the output content.obclient [SYS]> SET SERVEROUTPUT ON;Display the report information on the console.
Call the ASH PL package and specify the start and end times of the diagnostic period and the format for displaying the report.
Note
We recommend that you set the format to TEXT when you view the report on the console.
Display the report content on the console in TEXT format.
Set the diagnostic start time to
2024-02-22 19:26:47, the diagnostic end time to2024-06-22 19:27:07, and the report display format toTEXT. Set other parameters as needed.obclient [SYS]>CALL DBMS_WORKLOAD_REPOSITORY.ASH_REPORT(TO_DATE('2024-02-22 19:26:47', 'YYYY-MM-DD HH24:MI:SS'), TO_DATE('2024-06-22 19:27:07', 'YYYY-MM-DD HH24:MI:SS'), REPORT_TYPE=> 'TEXT');Here is a portion of the generated report:
ASH Report Cluster Name: test424 Observer Version: OceanBase 4.2.4.0 (200000342024061210-c4c0c18741e45a1d40889b6147c313257xxxxxxxxx) Operation System Info: Linux(3.10.0-327.ali2019.alios7.x86_64)_x86_64 User Input Begin Time: 2024-02-2219:26:47 User Input End Time: 2024-06-2219:27:07 Analysis Begin Time: 2024-06-1318:26:41 Analysis End Time: 2024-06-1414:51:12 Elapsed Time: 73471 Num of Sample: 14750 Average Active Sessions: 0.20 Top Active Tenants: - this section lists top active tenant information - Total Count: num of records during ash report analysis time period - Wait Event Count: num of records when session is on wait event - On CPU Count: num of records when session is on cpu - Avg Active Sessions: average active sessions during ash report analysis time period - % Activity: activity(cpu + wait) percentage for given tenant +---------+------------+------------------+-----------------------+-------------------+--------------------+-----------+ |Tenant ID|Session Type| Total Count| Wait Event Count| On CPU Count| Avg Active Sessions| % Activity| +---------+------------+------------------+-----------------------+-------------------+--------------------+-----------+ | 1004| BACKGROUND| 14725| 1670| 13055| 0.20| 99.83%| | 1004| FOREGROUND| 25| 11| 14| 0.00| 0.17%| +---------+------------+------------------+-----------------------+-------------------+--------------------+-----------+Display the report content on the console in HTML format.
Set the diagnostic start time to
2024-02-22 19:26:47, the diagnostic end time to2024-06-22 19:27:07, and the report display format toHTML. Set other parameters as needed.obclient [SYS]>CALL DBMS_WORKLOAD_REPOSITORY.ASH_REPORT(TO_DATE('2024-02-22 19:26:47', 'YYYY-MM-DD HH24:MI:SS'), TO_DATE('2024-06-22 19:27:07', 'YYYY-MM-DD HH24:MI:SS'), REPORT_TYPE=> 'HTML');Here is a portion of the generated report:
Observer Version: OceanBase 4.2.4.0 (200000342024061210-c4c0c18741e45a1d40889b6147c313257xxxxxxxxx) Operation System Info: Linux(3.10.0-327.ali2019.alios7.x86_64)_x86_64 User Input Begin Time: 2024-02-2219:26:47 User Input End Time: 2024-06-2219:27:07 Analysis Begin Time: 2024-06-1318:26:41 Analysis End Time: 2024-06-1414:54:29 Elapsed Time: 73668 Num of Sample: 14806 Average Active Sessions: 0.20 </pre><ul id=110></ul><a class="ash_html" name='Top Active Tenants'></a> <h2 class="ash_html">Top Active Tenants<br></h2><ul><li class='ash_html'>this section lists top active tenant information</li> <li class='ash_html'>Total Count: num of records during ash report analysis time period</li> <li class='ash_html'>Wait Event Count: num of records when session is on wait event</li> <li class='ash_html'>On CPU Count: num of records when session is on cpu</li> <li class='ash_html'>Avg Active Sessions: average active sessions during ash report analysis time period</li> <li class='ash_html'>% Activity: activity(cpu + wait) percentage for given tenant</li>
(Optional) View the report information on the local machine.
You can view the report information in TXT file or HTML page format. Here, we use the HTML page format as an example.
Log in to the physical server.
[admin@xxxxxx.eu95sqa /home/admin]Create an ASH report script file named
ash_report.htmlon the OBServer node.[admin@xxxxxx.eu95sqa /home/admin] $vim ash_report.htmlGenerate the script content.
set serveroutput on; tee ash_report.html CALL DBMS_WORKLOAD_REPOSITORY.ASH_REPORT( TO_DATE('2024-02-22 19:26:47', 'YYYY-MM-DD HH24:MI:SS'), TO_DATE('2024-06-22 19:27:07', 'YYYY-MM-DD HH24:MI:SS'), REPORT_TYPE=> 'HTML' ); noteeLog in to the database and run the
ash_report.htmlscript.$ obclient -h172.xx.xxx.xxx -Pxxxx -usys@oracle -pxxxx -Aobclient [SYS]> source ash_report.html;After the script is successfully executed, the HTML report content will be displayed on the console.
Exit the database and go to the physical server to find the
ash_report.htmlfile.[admin@k08j13249.eu95sqa /home/admin] $ls ALTER ash_report.htmlThe path of the
ash_report.htmlfile is found to behome/admin/ash_report.html.Export the file from the physical server to the local machine.
Open a new shell window and go to the directory where you want to save the file.
PS C:\Users\xxx\Desktop\ASH>Use the
scpcommand to import theash_report.htmlfile from the physical server to the local machine.scp admin@xx.xx.xx.xx:/home/admin/ash_report.html /Open the
ash_report.htmlfile in the local directory to view the report information.