— Clean environment
drop table gtt;
drop table gtt
*
ERROR at line 1:
ORA-00942: table or view does not exist
— Global temporary – preserve rows
create global temporary table gtt ( x int ) on commit preserve rows;
Table created.
— Keeps information until the end of the user session
select duration from user_tables where table_name = ‘GTT’;
DURATION
—————
SYS$SESSION
— Insert one row
insert into gtt values(1);
1 row created.
— Creates a TO lock
select sid, type, id1, id2, lmode from v$lock where id1=(select object_id from all_objects where object_name=’GTT’);
SID TY ID1 ID2 LMODE
———- — ———- ———- ———-
4343 TO 403115 1 3
— Commit transaction
commit;
Commit complete.
— TO lock continues…
select sid, type, id1, id2, lmode from v$lock where id1=(select object_id from all_objects where object_name=’GTT’);
SID TY ID1 ID2 LMODE
———- — ———- ———- ———-
4343 TO 403115 1 3
— Any user that tries to change the table
— Will receive: ORA-14450: attempt to access a transactional temp table already in use
alter table gtt add (y int);
alter table gtt add (y int)
*
ERROR at line 1:
ORA-14450: attempt to access a transactional temp table already in use
— Only after doing truncate
truncate table gtt;
Table truncated.
— TO lock disappears
select * from v$lock where id1=(select object_id from all_objects where object_name=’GTT’);
no rows selected
— With a global temporary table delete rows
drop table gtt;
Table dropped.
create global temporary table gtt ( x int ) on commit delete rows;
Table created.
— The duration is at transaction level
select duration from user_tables where table_name = ‘GTT’;
DURATION
—————
SYS$TRANSACTION
— Insert one row
insert into gtt values(1);
1 row created.
— Creates a TO lock
select sid, type, id1, id2, lmode from v$lock where id1=(select object_id from all_objects where object_name=’GTT’);
SID TY ID1 ID2 LMODE
———- — ———- ———- ———-
4343 TO 403116 1 3
— That disappears as soon as you commit the transaction
commit;
Commit complete.
select sid, type, id1, id2, lmode from v$lock where id1=(select object_id from all_objects where object_name=’GTT’);
no rows selected
— Clean up environment
drop table gtt;
Table dropped.