1. stop the database
2. start in restricted mode with "startup restrict"
3. enable table locks:
alter table scott.emp enable table lock;4. startup the database in normal mode, and you will now be able to aquire locks on the table.
Minimalistic Oracle contains a collection of practical examples from my encounters with Oracle technologies. When relevant, I also write about other technologies, like Linux or PostgreSQL. Many of the posts starts with "how to" since they derive directly from my own personal experience. My goal is to provide simple examples, so that they can be easily adapted to other situations.
alter table scott.emp enable table lock;4. startup the database in normal mode, and you will now be able to aquire locks on the table.
select SYS_CONTEXT('userenv','con_name') "container name", SYS_CONTEXT('userenv','con_id') "container id", SYS_CONTEXT('userenv','CURRENT_SCHEMA') "Current schema", SYS_CONTEXT('userenv','SID') "SID" FROM DUAL container name container id Current schema SID -------------------- -------------------- ------------------------------ ----- VEGDB01 3 SCOTT 362 --Update a the table rows: update emp set sal=1000; 14 rows updated.
select SYS_CONTEXT('userenv','con_name') "container name", SYS_CONTEXT('userenv','con_id') "container id", SYS_CONTEXT('userenv','CURRENT_SCHEMA') "Current schema", SYS_CONTEXT('userenv','SID') "SID" FROM DUAL; container name container id Current schema SID -------------------- -------------------- ------------------------------ ----- VEGDB01 3 SCOTT 130 --Update the same rows as in session# 1: update emp set sal=2000;
sqlplus / as sysdba @$ORACLE_HOME/rdbms/admin/utllockt.sql
WAITING_SESSION LOCK_TYPE MODE_REQUESTED MODE_HELD LOCK_ID1 LOCK_ID2 ----------------- ----------------- --------------- ------------ ----------------- ----------------- 362 None 130 Transaction Exclusive Exclusive 524308 17836
SELECT sess.sid,sess.serial#,sess.sql_id,s.plan_hash_value, s.child_number,sess.client_info,substr(sql_text,1,30) "sql text",sess.program,sess.pq_status, decode(sess.blocking_session_status,'VALID','blocked', 'NO HOLDER','Not blocked') "blocked?", sess.blocking_session "blocking session SID",sess.event FROM V$SESSION sess inner join v$sql s on (sess.sql_id = s.sql_id) WHERE sess.SID IN (130) and sess.sql_child_number = s.child_number;
SID | SERIAL# | SQL_ID | PLAN_HASH_VALUE | sql text | PROGRAM | PQ_STATUS | blocked? | blocking session SID | EVENT |
---|---|---|---|---|---|---|---|---|---|
130 |
9755 |
1gpj28ptjj43p | 1494045816 |
update emp set sal=2000 | sqlplus@ | ENABLED | blocked | 362 |
enq: TX - row lock contention |
exec dbms_application_info.set_client_info('Step one.'); exec dbms_application_info.set_module('module1','gettrades');
select SID,SERIAL#,SQL_ID,STATUS,osuser,machine,schemaname,MODULE,ACTION,CLIENT_INFO,LOGON_TIME,EVENT,STATE,FINAL_BLOCKING_SESSION "blocking" from v$session WHERE schemaname='SALES' AND STATUS='ACTIVE' UNION select SID,SERIAL#,SQL_ID,STATUS,osuser,machine,schemaname,MODULE,ACTION,CLIENT_INFO,LOGON_TIME,EVENT,STATE,FINAL_BLOCKING_SESSION "blocking" from v$session where SID = (SELECT FINAL_BLOCKING_SESSION FROM V$SESSION WHERE schemaname='SALES' AND STATUS='ACTIVE');
SID | SERIAL# | SQL_ID | STATUS | OSUSER | MACHINE | SCHEMANAME | MODULE | ACTION | CLIENT_INFO | LOGON_TIME | EVENT | STATE | blocking |
---|---|---|---|---|---|---|---|---|---|---|---|---|---|
32 | 4759 | 5jg1839cyxzgh | ACTIVE | oracle | mytestserver.com | SALES | DELETE MODULE | DELETE_SCHEMA | Delete XSD. | 15.02.2018 12:04:43 | library cache lock | WAITING | 2285 |
2285 | 48625 | g3bc37vx8fy3u | INACTIVE | JIM | COMPANY\PC-157 | SALES | SQL*Plus | 14.02.2018 14:08:57 | SQL*Net message from client | WAITING | NULL |
SQL> ALTER PACKAGE mypackage compile body; Warning: Package body altered with compilation errors. SQL> show errors Errors for PACKAGE BODY MVA3.MYPACKAGE: PLS-00201: identifier 'USER_LOCK.SLEEP' must be declared
cd $ORACLE_HOME/rdbms/admin sqlplus / as sysdba @userlock.sql
SELECT /*+ connect_by_filtering */ privilege#, LEVEL FROM sysauth$ CONNECT BY grantee# = PRIOR privilege# AND privilege# > 0 START WITH grantee# = :1 AND privilege# > 0; SELECT privilege# FROM sysauth$ WHERE (grantee# = :1 OR grantee# = 1) AND privilege# > 0;
select name, wait_class,parameter1,parameter2,parameter3 from v$event_name where wait_class = 'Concurrency' and name = 'library cache lock';
NAME | WAIT_CLASS | PARAMETER1 | PARAMETER2 | PARAMETER3 |
---|---|---|---|---|
library cache lock | Concurrency | handle address | lock address | 100*mode+namespace |
alter system set events '28401 trace name context forever, level 1';
SESSION_ID | OWNER | NAME | MODE_HELD | MODE_REQUESTED | LAST_CONVERT | BLOCKING_OTHERS |
---|---|---|---|---|---|---|
362 | VEGARDK | FAMILY_TREE | Row-X (SX) | None | 39 | Not Blocking |