Skip to content

Commit ffb8398

Browse files
[rdbms][oracle][profiling] add tvdxtat
1 parent 76dd748 commit ffb8398

File tree

8 files changed

+333
-54
lines changed

8 files changed

+333
-54
lines changed

RDBMS/ORACLE/SQL/tuning/Overview/tools.md

Lines changed: 116 additions & 42 deletions
Original file line numberDiff line numberDiff line change
@@ -29,61 +29,90 @@ Type:
2929

3030
[V$SESS_TIME_MODEL](https://docs.oracle.com/en/database/oracle/oracle-database/21/refrn/V-SESS_TIME_MODEL.html)
3131

32+
> You can know what **kind** of processing a database engine is doing on behalf of an application by looking at the time model statistics.
33+
3234
Check time spent on behalf of an application
3335
- opening new sessions
3436
- parsing SQL statements
3537
- processing calls with one of the engines (SQL, PL/SQL)
3638

37-
For a session
38-
```oracle
39-
SELECT ssn.sid
40-
,ssn.program
41-
,ssn.service_name
42-
,ssn.status
43-
,ssn.schemaname
44-
,ssn.state
45-
,ssn.event
46-
,ssn.logon_time
47-
,ssn.type
48-
-- ,ssn.*
49-
FROM v$session ssn
39+
> adding up the time reported by all children does NOT gives their parent's time
40+
> - a specific operation is not exclusively associated to a single child
41+
> - some operations aren’t attributed to any child.
42+
43+
#### All stats
44+
45+
For a session id
46+
```oracle
47+
SELECT
48+
ssn.sid,
49+
tm.stat_name,
50+
tm.value time_micros
51+
FROM v$session ssn INNER JOIN v$sess_time_model tm
52+
ON tm.sid = ssn.sid
5053
WHERE 1=1
51-
-- AND ssn.sid=6
52-
AND ssn.status ='ACTIVE'
53-
-- AND ssn.username = 'USERNAME'
54-
;
54+
AND ssn.client_identifier = 'profiling'
55+
-- AND ssn.sid = 42
56+
-- AND stat_name = 'DB time'
57+
ORDER BY
58+
-- tm.value DESC
59+
tm.stat_name ASC
60+
```
5561

56-
select ssn.sid,
57-
ssn.sql_id,
58-
ssn.command, ssn.*
59-
from v$sqltext qry, v$session ssn
60-
where ssn.sql_hash_value = qry.hash_value
61-
and ssn.sql_address = qry.address
62-
and ssn.username = 'USERNAME'
63-
order by qry.piece;
62+
#### DB time
6463

64+
For a session id
65+
```oracle
66+
SELECT
67+
ssn.sid,
68+
tm.stat_name,
69+
tm.value time_micros
70+
FROM v$session ssn INNER JOIN v$sess_time_model tm
71+
ON tm.sid = ssn.sid
72+
WHERE 1=1
73+
AND ssn.client_identifier = 'profiling'
74+
-- AND ssn.sid = 42
75+
AND stat_name = 'DB time'
76+
ORDER BY
77+
tm.value DESC
78+
```
79+
80+
#### Background time
6581

66-
SELECT sid, value
67-
FROM v$sess_time_model
82+
For a session id
83+
```oracle
84+
SELECT
85+
ssn.sid,
86+
tm.stat_name,
87+
tm.value time_micros
88+
FROM v$session ssn INNER JOIN v$sess_time_model tm
89+
ON tm.sid = ssn.sid
6890
WHERE 1=1
69-
-- AND sid = 42
70-
AND stat_name = 'DB time'
91+
AND ssn.client_identifier = 'profiling'
92+
-- AND ssn.sid = 42
93+
AND stat_name = 'background elapsed time'
94+
ORDER BY
95+
tm.value DESC
7196
```
7297

98+
#### On each leaf
7399

100+
> the time spent by the database engine waiting on user calls isn’t included
101+
> to know exactly what’s going on, information about wait classes and wait events is necessary.
74102
```oracle
75103
WITH
76104
db_time AS (SELECT sid, value
77105
FROM v$sess_time_model
78-
WHERE sid = 42
106+
WHERE sid = 22 -- <= SID HERE
79107
AND stat_name = 'DB time')
80108
SELECT ses.stat_name AS statistic,
81109
round(ses.value / 1E6, 3) AS seconds,
82110
round(ses.value / nullif(tot.value, 0) * 1E2, 1) AS "%"
83111
FROM v$sess_time_model ses, db_time tot
84-
WHERE ses.sid = tot.sid
85-
AND ses.stat_name <> 'DB time'
86-
AND ses.value > 0
112+
WHERE 1=1
113+
AND ses.sid = tot.sid
114+
AND ses.stat_name <> 'DB time'
115+
AND ses.value > 0
87116
ORDER BY ses.value DESC;
88117
```
89118

@@ -132,7 +161,7 @@ ALTER SESSION SET max_dump_file_size = 'unlimited'
132161

133162
#### Capture
134163

135-
##### Session level
164+
##### session level
136165

137166
###### from session itself
138167

@@ -192,6 +221,35 @@ END;
192221
```
193222

194223
###### from another session
224+
225+
Get session id
226+
```oracle
227+
SELECT 'session id is : ' || sys_context('userenv','sessionid')
228+
FROM dual;
229+
```
230+
231+
Or
232+
```oracle
233+
SELECT
234+
sss.logon_time
235+
,sss.username --tls_dtf
236+
,sss.osuser
237+
,sss.program
238+
,sss.client_info
239+
,sss.*
240+
FROM
241+
v$session sss
242+
WHERE 1=1
243+
-- AND sss.sid IN (1165,1152,23)
244+
AND sss.username = 'DBOFAP'
245+
AND sss.osuser = 'fap'
246+
-- AND sss.status = 'ACTIVE'
247+
AND sss.program LIKE 'sqlplus%'
248+
ORDER BY
249+
sss.client_info
250+
;
251+
```
252+
195253
Activate
196254
```oracle
197255
dbms_monitor.session_trace_enable(session_id => 127,
@@ -216,24 +274,35 @@ serial_num => 29)
216274

217275
##### client level
218276

277+
Set client identifier
278+
```oracle
279+
CALL dbms_session.set_identifier('client_identifier');
280+
```
281+
219282
Activate
220283
```oracle
221-
dbms_monitor.client_id_trace_enable(client_id => 'helicon.antognini.ch',
284+
dbms_monitor.client_id_trace_enable(client_id => 'client_identifier',
222285
waits => TRUE,
223286
binds => TRUE,
224287
plan_stat => 'first_execution')
225288
```
226289

227290
Deactivate
228291
```oracle
229-
dbms_monitor.client_id_trace_disable(client_id => 'helicon.antognini.ch')
292+
dbms_monitor.client_id_trace_disable(client_id => 'client_identifier')
230293
```
231294

232-
##### component level
295+
##### component level (module, action)
296+
297+
Get service name
298+
```oracle
299+
SELECT * FROM global_name;
300+
```
301+
You may get `FREEPDB1`
233302

234303
Activate
235304
```oracle
236-
dbms_monitor.serv_mod_act_trace_enable(service_name => 'DBM11203.antognini.ch',
305+
dbms_monitor.serv_mod_act_trace_enable(service_name => 'FREEPDB1',
237306
module_name => 'mymodule',
238307
action_name => 'myaction',
239308
waits => TRUE,
@@ -244,7 +313,7 @@ dbms_monitor.serv_mod_act_trace_enable(service_name => 'DBM11203.antognini.ch',
244313

245314
Deactivate
246315
```oracle
247-
dbms_monitor.serv_mod_act_trace_disable(service_name => 'DBM11203.antognini.ch',
316+
dbms_monitor.serv_mod_act_trace_disable(service_name => 'FREEPDB1',
248317
module_name => 'mymodule',
249318
action_name => 'myaction',
250319
instance_name => NULL)
@@ -255,20 +324,23 @@ dbms_monitor.serv_mod_act_trace_disable(service_name => 'DBM11203.antognini.ch'
255324

256325
Get instance name
257326
```oracle
258-
SELECT * FROM gv$instance
327+
SELECT instance_name
328+
FROM gv$instance
259329
```
260330

331+
You mey get `FREE`
332+
261333
Activate
262334
```oracle
263335
dbms_monitor.database_trace_enable(waits => TRUE,
264336
binds => TRUE,
265-
instance_name => 'DBM11203',
337+
instance_name => 'instance_name',
266338
plan_stat => 'first_execution')
267339
```
268340

269341
Deactivate
270342
```oracle
271-
dbms_monitor.database_trace_disable(instance_name => 'DBM11203')
343+
dbms_monitor.database_trace_disable(instance_name => 'instance_name')
272344
```
273345

274346
##### Sample output
@@ -429,6 +501,8 @@ Elapsed times include waiting on following events:
429501

430502
#### TVD$XTAT
431503

504+
[Source](https://antognini.ch/category/apmtools/tvdxtat/)
505+
432506
Install
433507

434508
> To fix those problems (TOP):

0 commit comments

Comments
 (0)