행위

트랜젝션 중인 데이터 조회 V$transaction

DB CAFE

thumb_up 추천메뉴 바로가기


1 트랜젝션 데이터 건수/블럭수 조회[편집]

  • From this v$transaction information we can compute the time required to roll-back a transaction with a query such as this, which joins v$session into v$transaction:
select
   t1.sid, 
   a.username, 
   t2.xidusn, 
   t2.used_urec, -- 트랜젝션에 사용된 테이블+인덱스 레코드 갯수
   t2.used_ublk  -- 트랜젝션에 사용된 테이블+인덱스 블럭 갯수 
from
   v$session     t1, 
   v$transaction t2
where
   t1.saddr = t2.ses_addr;

2 트랜젝션 처리중인 명령어 조회[편집]

  • Here is another script example using v$transaction which is extremely valuable for Oracle administrators who need to very quickly find out what is going on within their Oracle system.
select
   substr(s.username,1,18) username,
   substr(s.program,1,15) program,
   decode(s.command,
     0,'No Command',
     1,'Create Table',
     2,'Insert',
     3,'Select',
     6,'Update',
     7,'Delete',
     9,'Create Index',
     15,'Alter Table',
     21,'Create View',
     23,'Validate Index',
     35,'Alter Database',
     39,'Create Tablespace',
     41,'Drop Tablespace',
     40,'Alter Tablespace',
     53,'Drop User',
     62,'Analyze Table',
     63,'Analyze Index',
     s.command||': Other') command
from 
   v$session     s,
   v$process     p,
   v$transaction t,
   v$rollstat    r,
   v$rollname    n
where s.paddr = p.addr
and s.taddr = t.addr (+)
and t.xidusn = r.usn (+)
and r.usn = n.usn (+)
order by 1;
USERNAME PROGRAM COMMAND 
------------------ --------------- ----------------
APPS f45runm@corp-hp Select
APPS S:\ORANT\BIN\F5 Insert
APPS S:\ORANT\BIN\R3 No Command

3 사용자별 Rollback Segment 사용현황[편집]

  • used_urec : 트랜젝션에 사용된 테이블+인덱스 레코드(로우) 갯수
  • used_ublk : 트랜젝션에 사용된 테이블+인덱스 블럭 갯수
select  s.username, rn.name,     rs.curext 
           ,rs.curblk,  t.used_ublk, t.used_urec 
    from    v$transaction   t 
           ,v$session       s 
           ,v$rollname      rn 
           ,v$rollstat      rs 
    where  t.addr     = s.taddr 
    and    t.xidusn   = rn.usn 
    and    rn.usn     = rs.usn


  • APPS 유저가 ROLL03 롤백 세그먼트에서 3개의 블럭(USED_UBLK)에 94개 로우(USED_UREC)를 저장하고 있음.
USERNAME        NAME                CUREXT     CURBLK  USED_UBLK  USED_UREC 
--------------- --------------- ---------- ---------- ---------- ---------- 
APPS            ROLL03                   1        139          3         94

4 V$TRANSACTION 트랜젝션 목록 정보[편집]

  • V$TRANSACTION lists the active transactions in the system.
Column	Datatype	Description
ADDR	RAW(4 | 8)	Address of the transaction state object
XIDUSN	NUMBER	Undo segment number
XIDSLOT	NUMBER	Slot number
XIDSQN	NUMBER	Sequence number
UBAFIL	NUMBER	Undo block address (UBA) filenum
UBABLK	NUMBER	UBA block number
UBASQN	NUMBER	UBA sequence number
UBAREC	NUMBER	UBA record number
STATUS	VARCHAR2(16)	Status
START_TIME	VARCHAR2(20)	Start time (wall clock)
START_SCNB	NUMBER	Start system change number (SCN) base
START_SCNW	NUMBER	Start SCN wrap
START_UEXT	NUMBER	Start extent number
START_UBAFIL	NUMBER	Start UBA file number
START_UBABLK	NUMBER	Start UBA block number
START_UBASQN	NUMBER	Start UBA sequence number
START_UBAREC	NUMBER	Start UBA record number
SES_ADDR	RAW(4 | 8)	User session object address
FLAG	NUMBER	Flag
SPACE	VARCHAR2(3)	YES if a space transaction
RECURSIVE	VARCHAR2(3)	YES if a recursive transaction
NOUNDO	VARCHAR2(3)	YES if a no undo transaction
PTX	VARCHAR 2(3)	YES if parallel transaction
NAME	VARCHAR2(256)	Name of a named transaction
PRV_XIDUSN	NUMBER	Previous transaction undo segment number
PRV_XIDSLT	NUMBER	Previous transaction slot number
PRV_XIDSQN	NUMBER	Previous transaction sequence number
PTX_XIDUSN	NUMBER	Rollback segment number of the parent XID
PTX_XIDSLT	NUMBER	Slot number of the parent XID
PTX_XIDSQN	NUMBER	Sequence number of the parent XID
DSCN-B	NUMBER	This column is obsolete and maintained for backward compatibility. The value of this column is always equal to the value in DSCN_BASE.
DSCN-W	NUMBER	This column is obsolete and maintained for backward compatibility. The value of this column is always equal to the value in DSCN_WRAP.
USED_UBLK	NUMBER	Number of undo blocks used
USED_UREC	NUMBER	Number of undo records used
LOG_IO	NUMBER	Logical I/O
PHY_IO	NUMBER	Physical I/O
CR_GET	NUMBER	Consistent gets
CR_CHANGE	NUMBER	Consistent changes
START_DATE	DATE	Start time (wall clock)
DSCN_BASE	NUMBER	Dependent SCN base
DSCN_WRAP	NUMBER	Dependent SCN wrap
START_SCN	NUMBER	Start SCN
DEPENDENT_SCN	NUMBER	Dependent SCN
XID	RAW(8)	Transaction XID
PRV_XID	RAW(8)	Previous transaction XID
PTX_XID	RAW(8)	Parent transaction XID


  1. The v$transaction view lists the active transactions in the system.
  2. Oracle will insert an entry in v$transaction for each active transaction in the database. When the transaction is complete the v$transaction row will disappear.
  3. The v$transaction columns used_urec and v$transaction used_ublk show the number of undo records held by an active transaction. This is useful for monitoring long-running DML.
  4. The start_time column in the view v$transaction, the column shows only the starting time of the whole transaction.

5 오라클 사이트 질문/답변[편집]

Q : how much undo do you generate when you insert or update a row?

로우을 삽입하거나 업데이트할 때 얼마나 많은 언두가 발생 합니까?

A : it depends on what you’re actually doing, the amount of change you introduce, and the number of indexes affected.

   The key is to keep an eye on the used_urec and used_ublk colummns from v$transactions.
실제 수행 중인 작업, 도입한 변경 정도, 영향을 받은 인덱스 수에 따라 달라집니다. 
    핵심은 v$transactions의 Used_urec 및 Used_ublk 컬럼을 주시하는 것입니다.
   Consider the example of inserting data:  
데이터 삽입의 예를 고려하십시오.
   when you insert a row, you typically generate one undo record (used_urec) for the row, 
   but when you insert many rows using an array insert Oracle has an optimisation mechanism on undo record creation that 
   allows it to create one used_urec to cover all the changes you have made simultaneously to an individual block 
   - so used_urec could be much smaller than the number of rows processed. 
로우을 insert할 때 일반적으로 로우에 대해 하나의 언두 레코드(used_urec)를 생성하지만 array insert을 사용하여 많은 행을 삽입할 때 
    Oracle은 모든 변경 사항을 처리하기 위해 하나의 Used_urec를 생성하고 동시에 개별 블럭도 처리하도록 하는 언두 레코드 생성에 관한 최적화 메커니즘을 가지고 있습니다.   
    따라서 Used_urec는 처리되는 로우 수보다 훨씬 작을 수 있습니다.
   However, if you have indexes in place and are doing normal index maintenance on import, 
   then each table row would require each index to be updated, 
   so you would go back to one used_urec per table row plus one used_urec per index maintained per table row.
그러나 import시에 인덱스가 있고 일반 인덱스 유지 관리를 수행하는 경우 
    각 테이블 로우 마다 각각의 인덱스를 업데이트해야 하므로 테이블 로우당 하나의 used_urec와 테이블 로우당 관리되야 되는 인덱스별로 하나의 Used_urec를 처리해야합니다.
   So, when you look at the “big picture” there’s no obvious correlation between rows inserted and undo generated
   — until you look at the fine detail of exactly what you’re doing, and whether any optimisations apply. 
   (The details of the optimisation strategies available vary with the chosen insert mechanisms and with version of Oracle)
따라서 "큰 그림"을 볼 때 삽입된 로우과 생성된 언두 사이에 명확한 상관 관계는 없습니다. 
    수행 중인 작업과 최적화 적용 여부에 대한 세부적인 세부 사항을 확인할 때까지는 마찬가지입니다. 
    (사용 가능한 최적화 전략의 세부 사항은 선택한 삽입 메커니즘과 Oracle 버전에 따라 다릅니다.)