diff --git a/data-platform/autonomous-database/autonomous-json/ords_tracing/README.md b/data-platform/autonomous-database/autonomous-json/ords_tracing/README.md new file mode 100644 index 000000000..77707d770 --- /dev/null +++ b/data-platform/autonomous-database/autonomous-json/ords_tracing/README.md @@ -0,0 +1,13 @@ +This repository contains simple PL/SQL package allowing for tracing ORDS sessions in an Oracle Database + +- doc directory contains documentation +- sql directory contains installation and deinstallation scripts +- js directory contains JavaScript scripts to use the tool from Mongo shell + +# License + +Copyright (c) 2024 Oracle and/or its affiliates. + +Licensed under the Universal Permissive License (UPL), Version 1.0. + +See [LICENSE](https://github.com/oracle-devrel/technology-engineering/blob/main/LICENSE) for more details. diff --git a/data-platform/autonomous-database/autonomous-json/ords_tracing/doc/ORDS Tracing Tool.pdf b/data-platform/autonomous-database/autonomous-json/ords_tracing/doc/ORDS Tracing Tool.pdf new file mode 100644 index 000000000..45bca2bca Binary files /dev/null and b/data-platform/autonomous-database/autonomous-json/ords_tracing/doc/ORDS Tracing Tool.pdf differ diff --git a/data-platform/autonomous-database/autonomous-json/ords_tracing/js/create_job.js b/data-platform/autonomous-database/autonomous-json/ords_tracing/js/create_job.js new file mode 100644 index 000000000..7c692130b --- /dev/null +++ b/data-platform/autonomous-database/autonomous-json/ords_tracing/js/create_job.js @@ -0,0 +1 @@ +db.aggregate([{$sql:"begin ords_trc_pkg.create_job(5); end;"}]) diff --git a/data-platform/autonomous-database/autonomous-json/ords_tracing/js/drop_job.js b/data-platform/autonomous-database/autonomous-json/ords_tracing/js/drop_job.js new file mode 100644 index 000000000..eb56c586d --- /dev/null +++ b/data-platform/autonomous-database/autonomous-json/ords_tracing/js/drop_job.js @@ -0,0 +1 @@ +db.aggregate([{$sql:"begin ords_trc_pkg.drop_job; end;"}]) diff --git a/data-platform/autonomous-database/autonomous-json/ords_tracing/js/get_report.js b/data-platform/autonomous-database/autonomous-json/ords_tracing/js/get_report.js new file mode 100644 index 000000000..96a6ff841 --- /dev/null +++ b/data-platform/autonomous-database/autonomous-json/ords_tracing/js/get_report.js @@ -0,0 +1 @@ +db.aggregate([{$sql:"select ords_trc_pkg.get_report as report"}]) diff --git a/data-platform/autonomous-database/autonomous-json/ords_tracing/sql/install.sql b/data-platform/autonomous-database/autonomous-json/ords_tracing/sql/install.sql new file mode 100644 index 000000000..21ed98f67 --- /dev/null +++ b/data-platform/autonomous-database/autonomous-json/ords_tracing/sql/install.sql @@ -0,0 +1,3 @@ +@tables.sql +@ords_tracing.pls +@ords_tracing.plb diff --git a/data-platform/autonomous-database/autonomous-json/ords_tracing/sql/ords_tracing.plb b/data-platform/autonomous-database/autonomous-json/ords_tracing/sql/ords_tracing.plb new file mode 100644 index 000000000..edbb03079 --- /dev/null +++ b/data-platform/autonomous-database/autonomous-json/ords_tracing/sql/ords_tracing.plb @@ -0,0 +1,156 @@ +create or replace package body ords_trc_pkg +is + + procedure snapshot(p_username varchar2 := null) + is + v_plan clob := ''; + v_entries number(10) := 0; + begin + for r1 in (select * + from gv$session + where program = 'Oracle REST Data Services' + and username <> 'ORDS_PUBLIC_USER' + and username = nvl(upper(p_username),username)) loop + + -- sql_id + if r1.sql_id is not null then + select count(*) + into v_entries + from ords_trc_tab + where inst_id = r1.inst_id + and sid = r1.sid + and serial# = r1.serial# + and sql_id = r1.sql_id; + + if v_entries = 0 then + for r2 in (select * from dbms_xplan.display_cursor(r1.sql_id)) loop + v_plan := v_plan || r2.plan_table_output || chr(10); + end loop; + + insert into ords_trc_tab + (inst_id,sid,serial#,username,command,sql_exec_start,sql_id,sql_plan) + values + (r1.inst_id,r1.sid,r1.serial#,r1.username,r1.command,r1.sql_exec_start,r1.sql_id,v_plan); + end if; + end if; + -- prev_sql_id + if r1.prev_sql_id is not null then + select count(*) + into v_entries + from ords_trc_tab + where inst_id = r1.inst_id + and sid = r1.sid + and serial# = r1.serial# + and sql_id = r1.prev_sql_id; + + if v_entries = 0 then + for r2 in (select * from dbms_xplan.display_cursor(r1.prev_sql_id)) loop + v_plan := v_plan || r2.plan_table_output || chr(10); + end loop; + + insert into ords_trc_tab + (inst_id,sid,serial#,username,command,sql_exec_start,sql_id,sql_plan) + values + (r1.inst_id,r1.sid,r1.serial#,r1.username,r1.command,r1.prev_exec_start,r1.prev_sql_id,v_plan); + end if; + end if; + end loop; + commit; + end; + + procedure create_job(freq integer, p_username varchar2 := null) + is + v_job varchar2(200) := 'ORDS_TRC_JOB'; + v_block varchar2(200) := 'BEGIN ORDS_TRC_PKG.SNAPSHOT'; + n_of_jobs number(10); + begin + if p_username is not null then + v_job := v_job || '_' || upper(p_username); + v_block := v_block || '(''' ||upper(p_username)||''')'; + end if; + v_block := v_block||'; END;'; + + select count(*) + into n_of_jobs + from user_scheduler_jobs + where job_name = v_job; + + if n_of_jobs <> 0 then + raise_application_error(-20001,'You cannot trace the same database user in more than one job'); + end if; + + dbms_scheduler.create_job(v_job, + 'PLSQL_BLOCK', + v_block, + enabled => true, + repeat_interval => 'FREQ=SECONDLY;INTERVAL='||freq); + end; + + procedure drop_job(p_username varchar2 := null) + is + v_job varchar2(200) := 'ORDS_TRC_JOB'; + begin + if p_username is not null then + v_job := v_job || '_' || upper(p_username); + end if; + + dbms_scheduler.drop_job(v_job,defer => true); + end; + + function get_report (p_username varchar2 := null) return clob + is + v_rep clob := ''; + v_command varchar2(200); + prev_username varchar2(30) := ' '; + prev_session varchar2(200):= ' '; + begin + for r in (select * + from ords_trc_tab + where username = nvl(upper(p_username),username) + order by username, inst_id, sid, serial#, sql_exec_start, sql_id ) loop + if prev_username <> r.username then + -- start of new user section + prev_username := r.username; + v_rep := v_rep||chr(10)|| + ' USERNAME : '||r.username ||chr(10)|| + '======================================================'||chr(10); + end if; + + if prev_session <> r.inst_id||':'||r.sid||':'||r.serial# then + -- start of new sid section + prev_session := r.inst_id||':'||r.sid||':'||r.serial#; + v_rep := v_rep || chr(10) || + 'inst_id:sid:serial# : ' || prev_session || chr(10) || + '-----------------------------------------------------' || chr(10); + end if; + + select command_name + into v_command + from v$sqlcommand + where command_type = r.command; + + v_rep := v_rep || chr(10) || + 'command type : '||r.command||' ('||v_command||')'||chr(10)|| + 'plan : '||chr(10) || + r.sql_plan || chr(10); + end loop; + return v_rep; + end; + + procedure print_report(p_username varchar2 := null) + is + v_report clob := get_report(p_username); + begin + dbms_output.put_line(v_report); + end; + + procedure purge_logs(p_username varchar2 := null) + is + begin + delete from ords_trc_tab + where username = nvl(upper(p_username),username); + + commit; + end; +end; +/ diff --git a/data-platform/autonomous-database/autonomous-json/ords_tracing/sql/ords_tracing.pls b/data-platform/autonomous-database/autonomous-json/ords_tracing/sql/ords_tracing.pls new file mode 100644 index 000000000..11289ec47 --- /dev/null +++ b/data-platform/autonomous-database/autonomous-json/ords_tracing/sql/ords_tracing.pls @@ -0,0 +1,17 @@ +create or replace package ords_trc_pkg +is + type session_array_type is table of gv$session%rowtype; + + procedure snapshot(p_username varchar2 := null); + + procedure create_job(freq integer, p_username varchar2 := null); + + procedure drop_job(p_username varchar2 := null); + + function get_report(p_username varchar2 := null) return clob; + + procedure print_report(p_username varchar2 := null); + + procedure purge_logs(p_username varchar2 := null); +end; +/ \ No newline at end of file diff --git a/data-platform/autonomous-database/autonomous-json/ords_tracing/sql/remove.sql b/data-platform/autonomous-database/autonomous-json/ords_tracing/sql/remove.sql new file mode 100644 index 000000000..8ccf104e6 --- /dev/null +++ b/data-platform/autonomous-database/autonomous-json/ords_tracing/sql/remove.sql @@ -0,0 +1,2 @@ +drop package ords_trc_pkg +drop table ords_trc_tab; diff --git a/data-platform/autonomous-database/autonomous-json/ords_tracing/sql/tables.sql b/data-platform/autonomous-database/autonomous-json/ords_tracing/sql/tables.sql new file mode 100644 index 000000000..b833ff3b1 --- /dev/null +++ b/data-platform/autonomous-database/autonomous-json/ords_tracing/sql/tables.sql @@ -0,0 +1,10 @@ + +drop table if exists ords_trc_tab; +create table ords_trc_tab (inst_id number(10), + sid number(10), + serial# number(10), + username varchar2(30), + sql_exec_start date, + command number(10), + sql_id varchar2(200), + sql_plan clob);