RE: GTT Locks

  • From: Ravi Kulkarni <kulkarni.ravi@xxxxxxx>
  • To: oracle-l@xxxxxxxxxxxxx
  • Date: Wed, 03 Mar 2004 11:15:18 -0600

John,

The table GTT needs to be a Global Temporary table.

SQL> create table gtt (n1 number);

needs to be 

SQL> CREATE GLOBAL TEMPORARY TABLE GTT (n1 number) on commit preserve rows;


Thanks,
Ravi.

-----Original Message-----
From: oracle-l-bounce@xxxxxxxxxxxxx
[mailto:oracle-l-bounce@xxxxxxxxxxxxx]On Behalf Of Jonathan Lewis
Sent: Wednesday, March 03, 2004 12:51 AM
To: oracle-l@xxxxxxxxxxxxx
Subject: Re: GTT Locks



9.2.0.4:

SQL> create table gtt (n1 number);

Table created.

Elapsed: 00:00:00.00

SQL> select sid, username from v$session where user_name = 'TEST_USER';

       SID USERNAME
---------- ------------------------------
        16 TEST_USER

1 row selected.

Elapsed: 00:00:00.00
SQL> select * from V$lock where sid = 16;

no rows selected

Elapsed: 00:00:00.00
SQL> insert into gtt values(1);

1 row created.

Elapsed: 00:00:00.00
SQL> select * from V$lock where sid = 16;

ADDR     KADDR           SID TY        ID1        ID2      LMODE    REQUEST
 CTIME      BLOCK
-------- -------- ---------- -- ---------- ---------- ---------- ----------
------ ----------
67B84268 67B84374         16 TX     196647       7419          6          0
     0          0
67B4E074 67B4E088         16 TM      30492          0          3          0
     0          0

2 rows selected.

Object 30492 is the table definition for the GTT,
so I'm not reproducing your result.

In passing - has anyone got a system with an
object_id in excess of 2^22 ?  If so, what happens
when you use a GTT.  The OBJ column from x$BH
for GTT data is reported as the relative data block
address of the first block of the segment - and if
you have a 'default' build this means a GTT could
use the value power(2,22) + 8.  So what happens
if you have got through 4 million or so table, partition
and index definitions, and have a real object at that
number ?

Regards

Jonathan Lewis
http://www.jlcomp.demon.co.uk

The Co-operative Oracle Users' FAQ
http://www.jlcomp.demon.co.uk/faq/ind_faq.html

March 2004 Hotsos Symposium - The Burden of Proof
  Dynamic Sampling - an investigation
March 2004 Charlotte OUG (www.cltoug.org) CBO Tutorial
April 2004 Iceland
June  2004      UK - Optimising Oracle Seminar


----- Original Message ----- 
From: "Ravi Kulkarni" <kulkarni.ravi@xxxxxxx>
To: <oracle-l@xxxxxxxxxxxxx>
Sent: Tuesday, March 02, 2004 10:51 PM
Subject: GTT Locks


> Trying to understand the locking behavior of GTTs (Global Temporary
Tables) :
> (GTT_T is a GTT. T is a regular table)
>
> SQL> insert into gtt_t values (1000);
> 1 row created.
>
> SQL> select object_name, object_type, a.object_id, b.locked_mode from
dba_objects a, v$locked_object b where a.object_id=b.object_id;
> no rows selected
>
> SQL> insert into gtt_t select *from T;
> 1 row created.
>
> SQL> select object_name, object_type, a.object_id, b.locked_mode from
dba_objects a, v$locked_object b where a.object_id=b.object_id;
>
> OBJECT_NAME   OBJECT_TYPE    OBJECT_ID     OBJECT_ID LOCKED_MODE
> ----------------------------------------------------------------
> GTT_T        TABLE           204835       204835     3
>
>
> The user acquires a lock on the GTT for performing DML ONLY when selecting
from a Non-GTT.
> 1. How is this different from the first insert on GTT? (In either case, I
noticed a 'TO' lock-type in v$lock)
> 2. Where can I find more info on GTT-peculiarities ?
>
> TIA,
> Ravi.
>
> ----------------------------------------------------------------
> Please see the official ORACLE-L FAQ: http://www.orafaq.com
> ----------------------------------------------------------------
> To unsubscribe send email to:  oracle-l-request@xxxxxxxxxxxxx
> put 'unsubscribe' in the subject line.
> --
> Archives are at //www.freelists.org/archives/oracle-l/
> FAQ is at //www.freelists.org/help/fom-serve/cache/1.html
> -----------------------------------------------------------------
>


----------------------------------------------------------------
Please see the official ORACLE-L FAQ: http://www.orafaq.com
----------------------------------------------------------------
To unsubscribe send email to:  oracle-l-request@xxxxxxxxxxxxx
put 'unsubscribe' in the subject line.
--
Archives are at //www.freelists.org/archives/oracle-l/
FAQ is at //www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------

----------------------------------------------------------------
Please see the official ORACLE-L FAQ: http://www.orafaq.com
----------------------------------------------------------------
To unsubscribe send email to:  oracle-l-request@xxxxxxxxxxxxx
put 'unsubscribe' in the subject line.
--
Archives are at //www.freelists.org/archives/oracle-l/
FAQ is at //www.freelists.org/help/fom-serve/cache/1.html
-----------------------------------------------------------------

Other related posts: