You signed in with another tab or window. Reload to refresh your session.You signed out in another tab or window. Reload to refresh your session.You switched accounts on another tab or window. Reload to refresh your session.Dismiss alert
> Some of them are continuously updated, and others are only updated every 5 seconds.
@@ -59,6 +81,12 @@ ORDER BY
59
81
tm.stat_name ASC
60
82
```
61
83
84
+
For the whole system
85
+
```oracle
86
+
SELECT *
87
+
FROM v$sys_time_model
88
+
```
89
+
62
90
#### DB time
63
91
64
92
For a session id
@@ -118,31 +146,301 @@ ORDER BY ses.value DESC;
118
146
119
147
> Because DB time accounts only for the database processing time, the time spent by the database engine waiting on user calls isn’t included. As a result, with only the information provided by the time model statistics, you can’t know whether the problem is located inside or outside the database.
120
148
121
-
### Identify origin
149
+
Ih the problem is located outside, in the application itself, the application may spend say less than 2% of its time waiting for the database. If so, reducing this time to 1% will not reduce overall performance more than 1%.
122
150
123
-
Set
151
+
> The values are the ones that were set at hard parse time in the session that first parsed the SQL statement ! (TOP)
152
+
153
+
Get executed long queries
154
+
155
+
#### average number of active sessions
156
+
157
+
> DN time is the overall elapsed time spent by the database engine processing user calls (not time spent waiting on user calls).
158
+
159
+
> The average number of active sessions (AAS) is the rate at which the DB time increases at the system level.
160
+
161
+
Because DB time is the time elapsed, cumulated by CPU, in one minute on a 10 CPU instance, DB time can reach 600 (60*10).
162
+
163
+
> For example, if the DB time of a database instance increases by 1,860 seconds in 60 seconds, the average number of active sessions is 31 (1,860/60). This means that, during the 60-second period, on average 31 sessions were actively processing user calls.
164
+
165
+
If going from no activity to maximum activity (saturation) in 60 seconds
166
+
AAS = increase DB time / period = 600 / 60 = 10 = CPU count.
167
+
168
+
> As a rule of thumb, values much lower than the number of CPU cores mean that the system is almost idle. Inversely, values much higher than the number of CPU cores mean that the system is quite busy.
169
+
170
+
How can value go higher than the number of CPU cores ?
171
+
172
+
[But](https://support.quest.com/kb/4228410/what-are-average-active-sessions-in-a-database-agent-workload) it does not refer to session in v$sessions
173
+
> It is not a measure of how many sessions exist in the system at a given time, but rather how busy the database is.
174
+
175
+
#### wait
176
+
177
+
> you can determine
178
+
> - how much processing time a database instance is consuming
179
+
> - how much CPU it’s using for that processing.
180
+
>
181
+
> When the two values are equivalent, it means that the database instance isn’t experiencing any wait. If the difference between the two values is significant, you need to know which waits the server processes are waiting for.
> The values are the ones that were set at hard parse time in the session that first parsed the SQL statement ! (TOP)
143
212
144
-
Get executed long queries
213
+
##### session
214
+
215
+
Get wait time (value) for session
216
+
```oracle
217
+
SELECT *
218
+
FROM v$session_wait_class ssn_wt
219
+
WHERE 1=1
220
+
AND ssn_wt.sid = 205;
221
+
222
+
-- Missing :cry:
223
+
SELECT *
224
+
FROM v$sess_time_model
225
+
WHERE 1=1
226
+
--AND sid = 205
227
+
ORDER BY sid DESC
228
+
```
229
+
230
+
Get wait time (distribution) for session
231
+
```oracle
232
+
SELECT wait_class,
233
+
round(time_waited, 3) AS time_waited,
234
+
round(1E2 * ratio_to_report(time_waited) OVER (), 1) AS "%"
235
+
FROM (
236
+
SELECT sid, wait_class, time_waited / 1E2 AS time_waited
237
+
FROM v$session_wait_class
238
+
WHERE total_waits > 0
239
+
UNION ALL
240
+
SELECT sid, 'CPU', value / 1E6
241
+
FROM v$sess_time_model
242
+
WHERE stat_name = 'DB CPU'
243
+
)
244
+
WHERE sid = 205
245
+
ORDER BY 2 DESC;
246
+
```
247
+
248
+
##### system
249
+
250
+
```oracle
251
+
SELECT event,
252
+
round(time_waited, 3) AS time_waited,
253
+
round(1E2 * ratio_to_report(time_waited) OVER (), 1) AS "%"
254
+
FROM (
255
+
SELECT event, time_waited_micro / 1E6 AS time_waited
256
+
FROM v$system_event
257
+
WHERE total_waits > 0
258
+
UNION ALL
259
+
SELECT 'CPU', value / 1E6
260
+
FROM v$sys_time_model
261
+
WHERE stat_name = 'DB CPU'
262
+
)
263
+
ORDER BY 2 DESC;
264
+
```
265
+
266
+
If most of the time is elapsed on idle wait event (SQL*Net message from client), tThis indicates that the database engine is waiting for the application to submit some work.
267
+
268
+
> The other essential information provided by this resource usage profile may be that, when the database engine is processing user calls, it’s almost always doing disk I/O operations that read a single block (db file sequential read).
269
+
270
+
I/O : Average waiting time on I/O
271
+
```oracle
272
+
SELECT time_waited_micro/total_waits/1E3 AS avg_wait_ms
273
+
FROM v$system_event
274
+
WHERE event = 'db file sequential read';
275
+
```
276
+
277
+
I/O : Histogram waiting time
278
+
```oracle
279
+
SELECT wait_time_milli, wait_count, 100*ratio_to_report(wait_count) OVER () AS "%"
The identification of the session (sid, serial#, saddr and audsid), whether it’s a BACKGROUND or USER session (type), and when it was initialized (logon_time).
359
+
The identification of the user that opened the session (username and user#), the current schema (schemaname), and the name of the service used to connect to the database engine (service_name).
360
+
The application using the session (program), which machine it was started on (machine), which process ID it has (process), and the name of the OS user who started it (osuser).
361
+
The type of server-side process (server) which can be either DEDICATED, SHARED, PSEUDO, POOLED or NONE, and its address (paddr).
362
+
The address of the currently active transaction (taddr).
363
+
The status of the session (status) which can be either ACTIVE, INACTIVE, KILLED, SNIPED, or CACHED and how many seconds it’s been in that state for (last_call_et). When investigating a performance problem, you’re usually interested in the sessions marked as ACTIVE only.
364
+
The type of the SQL statement in execution (command), the identification of the cursor related to it (sql_address, sql_hash_value, sql_id and sql_child_number), when the execution was started (sql_exec_start), and its execution ID (sql_exec_id). The execution ID is an integer value that identifies, along with sql_exec_start, one specific execution. It’s necessary because the same cursor can be executed several times per second (note that the datatype of the sql_exec_start column is DATE).
365
+
The identification of the previous cursor that was executed (prev_sql_address, prev_hash_value, prev_sql_id and prev_child_number), when the previous execution was started (prev_exec_start), and its execution ID (prev_exec_id).
366
+
If a PL/SQL call is in execution, the identification of the top-level program and subprogram (plsql_entry_object_id and plsql_entry_subprogram_id) that was called, and the program and subprogram (plsql_object_id and plsql_subprogram_id) that is currently in execution. Note that plsql_object_id and plsql_subprogram_id are set to NULL if the session is executing a SQL statement.
367
+
The session attributes (client_identifier, module, action, and client_info), if the application using the session sets them.
368
+
If the session is currently waiting (in which case the state column is set to WAITING), the name of the wait event it’s waiting for (event), its wait class (wait_class and wait_class#), details about the wait event (p1text, p1, p1raw, p2text, p2, p2raw, p3text, p3, and p3raw), and how much time the session has been waiting for that wait event (seconds_in_wait and, from 11.1 onward, wait_time_micro). Be aware that if the state column isn’t equal to WAITING, the session is on CPU (provided the status column is equal to ACTIVE). In this case, the columns related to the wait event contain information about the last wait.
369
+
Whether the session is blocked by another session (if this is the case, blocking_session_status is set to VALID) and, if the session is waiting, which session is blocking it (blocking_instance and blocking_session).
370
+
If the session is currently blocked and waiting for a specific row (for example, for a row lock), the identification of the row it’s waiting for (row_wait_obj#, row_wait_file#, row_wait_block#, and row_wait_row#). If the session isn’t waiting for a locked row, the row_wait_obj# column is equal to the value -1.
371
+
372
+
Other related view:
373
+
- v$session_wait : wait events
374
+
- v$session_blockers : blocked sessions.
375
+
376
+
### Session history (ASH)
377
+
378
+
One-hour history.
379
+
380
+
Carried by `MMNL` background process:
381
+
- poll `v$session` each second
382
+
- filter out inactive session
383
+
- store 'events' (if activity has changed, eg. CPU or User I/O) and `sqlId`
384
+
385
+
Size
386
+
```oracle
387
+
SELECT name, pool, bytes
388
+
FROM v$sgastat
389
+
WHERE name = 'ASH buffers';
390
+
```
391
+
392
+
Retention
393
+
```oracle
394
+
SELECT max(sample_time) - min(sample_time) AS interval
395
+
FROM v$active_session_history;
396
+
```
397
+
398
+
```oracle
399
+
SELECT
400
+
sample_time
401
+
,session_id
402
+
,session_serial#
403
+
,session_state
404
+
,sql_id
405
+
,in_sql_execution SQL
406
+
,in_plsql_execution PLSQL
407
+
,sql_plan_operation || ' ' || sql_plan_options
408
+
,'v$active_session_history=>'
409
+
--,ssn_hst.*
410
+
FROM v$active_session_history ssn_hst
411
+
WHERE 1=1
412
+
AND session_id = 205
413
+
ORDER BY ssn_hst.sample_time ASC;
414
+
```
415
+
416
+
Top 10
417
+
```oracle
418
+
SELECT activity_pct,
419
+
db_time,
420
+
sql_id
421
+
FROM (
422
+
SELECT round(100 * ratio_to_report(count(*)) OVER (), 1) AS activity_pct,
423
+
count(*) AS db_time,
424
+
sql_id
425
+
FROM v$active_session_history
426
+
WHERE sample_time BETWEEN to_timestamp('2025-01-09 10:00:00', 'YYYY-MM-DD HH24:MI:SS')
427
+
AND to_timestamp('2025-01-09 12:00:00', 'YYYY-MM-DD HH24:MI:SS')
0 commit comments