Oracle FAQ Your Portal to the Oracle Knowledge Grid
HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US
 

Home -> Community -> Mailing Lists -> Oracle-L -> Re: Question with lock script - phantom objects

Re: Question with lock script - phantom objects

From: Mladen Gogala <mladen_at_wangtrading.com>
Date: Mon, 06 Oct 2003 08:09:32 -0800
Message-ID: <F001.005D22C4.20031006080932@fatcity.com>


The script as such works, but I do not like user scripts accessing objects owned by SYS directly. I normally use modified version of utlockt.sql in which dba_locks_temp and lock_holders are global temporary tables in my schema which do not get dropped & re-created every time.

On Mon, 2003-10-06 at 11:29, Jamadagni, Rajendra wrote:
> Hi all,
>
> I am using following script to see locks in the DB. Do you see any
> problems with it?
>
> ======================== cut here =====================
> connect / as sysdba
> set linesize 200 feedback off heading on pagesize 100
> column sid format a9
> column res heading 'Resource Type' format a15 trunc
> column id1 format 9999999 noprint
> column id2 format 9999999 noprint
> column lmode heading 'Lock Held' format a14
> column request heading 'Lock Req.' format a14
> column serial# format 99999
> column username format a10
> column terminal heading Term format a8
> column table_name format a20 trunc
> column owner format a10
> column inst_id format a5
> select --+ no_merge(l) no_merge(s)
> (select instance_name
> from sys.gv_$instance
> where instance_number = l.inst_id) inst_id,
> l.sid || ',' || s.serial# sid,
> s.username,
> replace(s.terminal,'WTS-') terminal,
> decode(l.type,
> 'RW','RW-Row Wait Enq',
> 'TM','TM-DML Enq',
> 'TX','TX-Trans Enq',
> 'UL','UL-User',l.type||'-System') res,
> t.name table_name,u.name owner,
> l.id1,l.id2,
> decode(l.lmode,1,'No Lock',
> 2,'Row Share',
> 3,'Row Excl',
> 4,'Share',
> 5,'Shr Row Excl',
> 6,'Excl',null) lmode,
> decode(l.request,1,'No Lock',
> 2,'Row Share',
> 3,'Row Excl',
> 4,'Share',
> 5,'Shr Row Excl',
> 6,'Excl',null) request
> from sys.gv_$lock l, sys.gv_$session s, sys.user$ u,sys.obj$ t
> where l.sid = s.sid
> and s.type != 'BACKGROUND'
> and t.obj# = l.id1
> and u.user# = t.owner#
> and l.inst_id = s.inst_id
> /
> prompt
> set feedback on
> prompt
> exit
> ======================== cut here =====================
>
> Btu here is the problem ... once in a while (aka many times a day)
> when we run this script, we see objects as locked by some user which
> should NEVER be even accessed. We have one schema that deals with out
> affiliates, and it is practically independent of other schema in the
> database. Still sometimes we see objects within the affiliate schema
> beign accesses by other users who have nothing to do (or the code they
> execute has nothing to do) with the objects displayed in the list.
>
> One peculier thing I have noted, is affiliate schema used private
> synonyms and the objects listed in the lock scripts are _always_
> private synonyms pointing to objects in the affiliate schema and the
> private synonym belongs to the user who is _not_ the locking user.
>
> e.g.
>
> ABC1 47,820 BROWNBRE BRS02 TX-Trans Enq
> SYSTEM_NETWORK_HIST MURPHYM Excl
>
> here locking user ius brownbre locking system_network_hist owned by
> murphym. Actually the table is owned by affiliate and murphym has a
> private synonym to the table.
>
> Any clues? DB is 9202 RAC.
> TIA
> Raj
>
> --------------------------------------------------------------------------------
> Rajendra dot Jamadagni at nospamespn dot com
> All Views expressed in this email are strictly personal.
> QOTD: Any clod can have facts, having an opinion is an art !

-- 
Mladen Gogala
Oracle DBA




Note:
This message is for the named person's use only.  It may contain confidential, proprietary or legally privileged information.  No confidentiality or privilege is waived or lost by any mistransmission.  If you receive this message in error, please immediately delete it and all copies of it from your system, destroy any hard copies of it and notify the sender.  You must not, directly or indirectly, use, disclose, distribute, print, or copy any part of this message if you are not the intended recipient. Wang Trading LLC and any of its subsidiaries each reserve the right to monitor all e-mail communications through its networks.
Any views expressed in this message are those of the individual sender, except where the message states otherwise and the sender is authorized to state them to be the views of any such entity.

-- 
Please see the official ORACLE-L FAQ: http://www.orafaq.net
-- 
Author: Mladen Gogala
  INET: mladen_at_wangtrading.com

Fat City Network Services    -- 858-538-5051 http://www.fatcity.com
San Diego, California        -- Mailing list and web hosting services
---------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message
to: ListGuru_at_fatcity.com (note EXACT spelling of 'ListGuru') and in
the message BODY, include a line containing: UNSUB ORACLE-L
(or the name of mailing list you want to be removed from).  You may
also send the HELP command for other information (like subscribing).
Received on Mon Oct 06 2003 - 11:09:32 CDT

Original text of this message

HOME | ASK QUESTION | ADD INFO | SEARCH | E-MAIL US