Hello and thank you for your response.
Sorry I could not provide a live example SQL.
I have an application running in JBoss connecting to a database Reporting_DB and executes SQLs there.
The SQLs actually would access views in the Reporting_DB.
The views are accessing tables which are in a remote DB, say ReadOnlyStandby_DB accessed over a DB link to a remote database.
Here is a simple schematic:
Application --Network--> Reporting_DB ---DB Link--> ReadOnlyStandby_DB
ORM sql ---> View --> Table
SQL Signature:
Example of SQL seen in Reporting_DB:
The application uses some ORM (hibernate), so the SQLs are always changing as seen in the Reporting_DB:
select this_.Column1 as Column1_485_0_, this_.Column2 as Column2_485_0_, this_.Column3 as AUDIT3_485_0 etc.
Example of SQL seen in ReadOnlyStandby_DB
The sql seen in the ReadOnlyStandby_DB looks like this:
SELECT "A1"."col1" ... FROM "TABLE_1" where CONDITION ... UNION ALL ...
The users are complaining that the performance is slow, developers are sharing application logs that show SQLs are timing out with slowness.
The final database where SQL is executed is a Data Guard read only Standby database.
I have OEM on Reporting_DB and ReadOnlyStandby_DB but the app server (JBOSS) is external to my jurisdiction and have no access or insight.
How can I get the following details:
1) Connect the dots for session: How to connect the dots from App, db session to Reporting_DB, db session to ReadOnlyStandby_DB
2) Session Trace: How to trace session coming from DB link on ReadOnlyStandby_DB
3) SQL Analysis: The SQL on Reporting_DB is not the same on ReadOnlyStandby_DB; it seems to change. How to connect SQL "a" on Reporting_DB and its related SQL "b" on ReadOnlyStandby_DB ?
For (1) and (3), the best method is well instrumented code.
For example, on my primary session I could run:
dbms_application_info.set_client_info@remote_db('I am coming from primary session '||sys_context('userenv','sid'));
which would directly link the remote session to this one.
If you can't do that, then internally we track it to some degree because opening a database link automatically opens a cross-database transaction. For example
SQL> create database link remote_db using 'pdb21b';
Database link created.
SQL> select * from emp@pdb21b;
select * from emp@pdb21b
*
ERROR at line 1:
ORA-02019: connection description for remote database not found
SQL> select * from emp@remote_db;
EMPNO ENAME JOB MGR HIREDATE SAL COMM DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
7369 SMITH CLERK 7902 17-DEC-80 800 20
7499 ALLEN SALESMAN 7698 20-FEB-81 1600 300 30
7521 WARD SALESMAN 7698 22-FEB-81 1250 500 30
7566 JONES MANAGER 7839 02-APR-81 2975 20
7654 MARTIN SALESMAN 7698 28-SEP-81 1250 1400 30
7698 BLAKE MANAGER 7839 01-MAY-81 2850 30
7782 CLARK MANAGER 7839 09-JUN-81 2450 10
7788 SCOTT ANALYST 7566 09-DEC-82 3000 20
7839 KING PRESIDENT 17-NOV-81 5000 10
7844 TURNER SALESMAN 7698 08-SEP-81 1500 30
7876 ADAMS CLERK 7788 12-JAN-83 1100 20
7900 JAMES CLERK 7698 03-DEC-81 950 30
7902 FORD ANALYST 7566 03-DEC-81 3000 20
7934 MILLER CLERK 7782 23-JAN-82 1300 10
14 rows selected.
SQL> select * from v$transaction
2 @pr
==============================
ADDR : 00007FF9F7585138
XIDUSN : 10
XIDSLOT : 13
XIDSQN : 854740
UBAFIL : 0
UBABLK : 0
UBASQN : 0
UBAREC : 0
STATUS : ACTIVE
START_TIME : 10/30/25 15:52:33
START_SCNB : 1932923708
START_SCNW : 3802
START_UEXT : 1
START_UBAFIL : 11
START_UBABLK : 188
START_UBASQN : -3048
START_UBAREC : 36
SES_ADDR : 00007FFA05974FA8
FLAG : 4199939
SPACE : NO
RECURSIVE : NO
NOUNDO : NO
PTX : NO
NAME :
PRV_XIDUSN : 0
PRV_XIDSLT : 0
PRV_XIDSQN : 0
PTX_XIDUSN : 0
PTX_XIDSLT : 0
PTX_XIDSQN : 0
DSCN-B : 0
DSCN-W : 0
USED_UBLK : 1
USED_UREC : 1
LOG_IO : 4
PHY_IO : 3
CR_GET : 358
CR_CHANGE : 0
START_DATE : 30-OCT-25
DSCN_BASE : 0
DSCN_WRAP : 0
START_SCN : 16331398583100
DEPENDENT_SCN : 0
XID : 0A000D00D40A0D00
PRV_XID : 0000000000000000
PTX_XID : 0000000000000000
CON_ID : 3
PL/SQL procedure successfully completed.
SQL> select * from GV$GLOBAL_TRANSACTION
2 @pr
==============================
INST_ID : 1
FORMATID : 306206
GLOBALID : 5044423231412E64323235376164622E31302E31332E383534373430
BRANCHID : 0000
BRANCHES : 1
REFCOUNT : 1
PREPARECOUNT : 0
STATE : [ORACLE COORDINATED]ACTIVE
FLAGS : 512
COUPLING : TIGHTLY COUPLED
CON_ID : 0
PL/SQL procedure successfully completed.
Turning all of that into a linkage identifying the actual session is non-trivial and you'd need some SYSDBA access to create a view to let you see the details.
On the *remote* db I could run this
SQL> conn sys/admin@remote_db as sysdba
Connected.
SQL> select
2 s.ksusemnm source_host
3 ,s.ksusepid source_pid
4 ,g.k2gtitid_ora global_txn
5 ,s.indx session_id
6 ,s.ksuseser session_serial#
7 ,s.ksuudnam username
8 from x$k2gte g,
9 x$ktcxb t,
10 x$ksuse s
11 where g.k2gtdxcb = t.ktcxbxba
12 and g.k2gtdses = t.ktcxbses
13 and s.addr = g.k2gtdses
14 @pr
==============================
SOURCE_HOST : BAILEY
SOURCE_PID : 6800:14728
GLOBAL_TXN : LOCAL_DB.d2257adb.10.13.854740
SESSION_ID : 324
SESSION_SERIAL# : 17639
USERNAME : SCOTT
which says a transaction initiated from LOCAL_DB from machine BAILEY with OS process 6800:14738 is connected to this database as session 324.
And the same query can be run on the local db to see the reverse
SQL> conn sys/admin@Pdb21b as sysdba
Connected.
SQL> select
2 s.ksusemnm source_host
3 ,s.ksusepid source_pid
4 ,g.k2gtitid_ora global_txn
5 ,s.indx session_id
6 ,s.ksuseser session_serial#
7 ,s.ksuudnam username
8 from x$k2gte g,
9 x$ktcxb t,
10 x$ksuse s
11 where g.k2gtdxcb = t.ktcxbxba
12 and g.k2gtdses = t.ktcxbses
13 and s.addr = g.k2gtdses
14 @pr
==============================
SOURCE_HOST : WORKGROUP\BAILEY
SOURCE_PID : 4692:46744
GLOBAL_TXN : LOCAL_DB.d2257adb.10.13.854740
SESSION_ID : 800
SESSION_SERIAL# : 8577
USERNAME : SCOTT
PL/SQL procedure successfully completed.
which says my session 800 is connected to remote machine WORKGROUP\BAILEY (I'm using the same machine for both db's) with OS pid 4692:46744
(You can see why its just easier to instrument your code).
In terms of automatically creating traces on the remote node, you could use a login trigger for that, eg
create or replace
trigger trace_stuff
after logon on SCOTT.schema
begin
dbms_monitor.SESSION_TRACE_ENABLE(waits=>true);
exception
when others then null;
end;