Oracle FAQ | Your Portal to the Oracle Knowledge Grid |
Home -> Community -> Mailing Lists -> Oracle-L -> RE: Global Temp Tables and Indexes
Jack,
I was looking into this last week and the only view I could find was v$sort_usage.
I then had to match the sqladdr and sqlhash shown in v$sort_usage with (say) v$sqlarea to confirm the statement that was used to determine if it was due to a sort or if it was due to a temporary table.
As for indexes on temp tables, my simple test below seemed to suggest they also end up in the temp tablespace and that you can not put them elsewhere.
HTH,
Bruce
See below.
SQL> select * from v$sort_usage;
no rows selected
SQL> select temporary from dba_tables where table_name='TEMP_CHARGE_DETAILS';
T
-
Y
1 row selected.
SQL> insert into temp_charge_details values ( 'A' , 12345 , 11111,54555,'Y','28-jun-2001');
1 row created.
SQL> select * from v$sort_usage;
USER SESSION_ SESSION_NUM SQLADDR SQLHASH
------------------------------ -------- ----------- -------- ----------
TABLESPACE CONTENTS SEGTYPE SEGFILE# SEGBLK#
------------------------------- --------- --------- ---------- ----------
EXTENTS BLOCKS SEGRFNO#
---------- ---------- ----------
ENTERPRISE 1C1EC800 2419 116FA178 2764439617 TEMP PERMANENT DATA 5 2 1 129 5
1 row selected.
SQL>
SQL> roll;
Rollback complete.
SQL> select * from v$sort_usage;
USER SESSION_ SESSION_NUM SQLADDR SQLHASH
------------------------------ -------- ----------- -------- ----------
TABLESPACE CONTENTS SEGTYPE SEGFILE# SEGBLK#
------------------------------- --------- --------- ---------- ----------
EXTENTS BLOCKS SEGRFNO#
---------- ---------- ----------
ENTERPRISE 1C1EC800 2419 116FA178 2764439617 TEMP PERMANENT DATA 5 2 1 129 5
1 row selected.
SQL> truncate table abc.temp_charge_details;
Table truncated.
SQL> select * from v$sort_usage;
no rows selected
SQL> --- index test on GTT
SQL> create index test on abc.temp_charge_details ( charged_ind);
Index created.
SQL> select * from v$sort_usage;
no rows selected
SQL> insert into temp_charge_details values ( 'A' , 12345 , 11111,54555,'Y','28-jun-2001');
1 row created.
SQL> select * from v$sort_usage;
USER SESSION_ SESSION_NUM SQLADDR SQLHASH
------------------------------ -------- ----------- -------- ----------
TABLESPACE CONTENTS SEGTYPE SEGFILE# SEGBLK#
------------------------------- --------- --------- ---------- ----------
EXTENTS BLOCKS SEGRFNO#
---------- ---------- ----------
ENTERPRISE 1C1EC800 2419 116FA178 2764439617 TEMP PERMANENT DATA 5 2 1 129 5 ENTERPRISE 1C1EC800 2419 116FA178 2764439617 TEMP PERMANENT INDEX 5 132 1 129 5
2 rows selected.
SQL> roll;
Rollback complete.
SQL> drop index test;
drop index test
*
ERROR at line 1:
ORA-14452: attempt to create, alter or drop an index on temporary table
already
in use
SQL> truncate table abc.temp_charge_details;
Table truncated.
SQL> drop index test;
Index dropped.
SQL> SQL> SQL> create index test on metpro.temp_charge_details ( charged_ind)tablespace users;
*
SQL>
-----Original Message-----
Sent: Thursday, 28 June 2001 10:01
Hi,
Using Oracle8i 8.1.6...
I've created a Temp table and inserted a couple of rows, but there seems to be no way to verify that it's segment(s) is(are) in the temp tablespace of the creating user. I've looked at every USER*, DBA*, and v$* view I can find - Tablespace_Name is null in all of them. I inserted the rows because I know that the first extent of a temp table is not allocated until the first insert.
I'd like to see that the segment is where I think it is because I want another user whose temp t.s. is on another drive to create an index on that table. That's the only way I can think of to get an index on a temp table in another tablespace - for performance considerations.
Anybody know how to verify the tablespace? Will my proposed method for getting the temp index on the temp table on another drive work? Any suggestions?
Thanks.
Jack
Fat City Network Services -- (858) 538-5051 FAX: (858) 538-5051 San Diego, California -- Public Internet access / Mailing Liststo: 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 Wed Jun 27 2001 - 18:12:56 CDT
--------------------------------------------------------------------
To REMOVE yourself from this mailing list, send an E-Mail message