oerr ora 14450
14450, 00000, "attempt to access a transactional temp table already in use"
// *Cause: An attempt was made to access a transactional temporary table that
// has been already populated by a concurrent transaction of the same
// session.
// *Action: do not attempt to access the temporary table until the
// concurrent transaction has committed or aborted.
在ORACLE数据中修改会话级临时表时,有可能会遇到ORA-14550错误,那么为什么会话级全局临时表会报ORA-14450错误呢
CREATE GLOBAL TEMPORARY TABLE TEMP_TEST(NAME VARCHAR2(12)) ON COMMIT PRESERVE ROWS;
INSERT INTO TEMP_TEST VALUES('nick');
COMMIT;
ALTER TABLE TEMP_TEST ADD SEX NUMBER(1) ;
ALTER TABLE TEMP_TEST ADD SEX NUMBER(1)
*
ERROR at line 1:
ORA-14450: attempt to access a transactional temp table already in use
如上所示,修改会话级临时表时遇到了ORA-14450错误,那么有哪些解决方法呢? 这时需要断开会话或执行TRUNCATE语句:
TRUNCATE TABLE TEMP_TEST;
ALTER TABLE TEMP_TEST ADD SEX NUMBER(1);
如下所示,我们模拟一个会话在操作临时表TEMP_TEST, 另外一个会话准备修改它,如下所示(实际场景可能更复杂,可能涉及多个会话而不是仅仅两个会话)
会话1:
SET SQLPROMPT "SQLSESSION 1 >"
CREATE GLOBAL TEMPORARY TABLE TEMP_TEST(NAME VARCHAR2(12)) ON COMMIT PRESERVE ROWS;
INSERT INTO TEMP_TEST VALUES('nick');
COMMIT;
会话2:
SET SQLPROMPT "SESSION 2 >"
SESSION 2 >ALTER TABLE TEMP_TEST ADD SEX NUMBER(1);
ALTER TABLE TEMP_TEST ADD SEX NUMBER(1)
*
ERROR at line 1:
ORA-14450: attempt to access a transactional temp table already in use
那么此时,会话1是其它用户登录的。比如应用程序等,你不可能要求所有会话都去执行TRUNCATE操作,这个时候该怎么处理呢?
此时你可以使用下面步骤解决这个问题。
Step 1、以sys或system登录数据库,先从DBA_OBJECTS中查询到该表的OBJECT_ID:
SELECT OWNER, OBJECT_ID, OBJECT_TYPE
FROM DBA_OBJECTS
WHERE OBJECT_NAME = 'TEMP_TEST'
AND OBJECT_TYPE = 'TABLE';
Step 2、根据查到的OBJECT_ID知道使用该表的SESSION:
SELECT ADDR, KADDR, SID,LMODE FROM V$LOCK WHERE ID1=&OBJECT_ID;
Step 3、通过下面SQL找到对应的会话并生成KILL SESSION的执行语句
SET COL kill_session FOR A80;
select a.sid,
a.serial#,
a.status,
a.paddr,
'alter system kill session ''' || a.sid || ',' || a.serial# || ''' immediate;' AS kill_session
FROM v$session a
WHERE a.sid in (select sid from v$enqueue_lock t where t.type = 'TO')
and a.sid = &sid;
Step 4、查看会话状态,并执行ALTER SYSTEM KILL SESSION语句杀掉这些进程:
「喜欢这篇文章,您的关注和赞赏是给作者最好的鼓励」
关注作者
【版权声明】本文为墨天轮用户原创内容,转载时必须标注文章的来源(墨天轮),文章链接,文章作者等基本信息,否则作者和墨天轮有权追究责任。如果您发现墨天轮中有涉嫌抄袭或者侵权的内容,欢迎发送邮件至:contact@modb.pro进行举报,并提供相关证据,一经查实,墨天轮将立刻删除相关内容。




