Search This Blog

Total Pageviews

Saturday 6 October 2018

Oracle 18c Cancel a SQL Statement for session !!!!


 Oracle 18c Cancel a SQL Statement for session !!!!

Oracle 18c cancel sql


SQL> def
DEFINE _DATE           = "06-OCT-18" (CHAR)
DEFINE _CONNECT_IDENTIFIER = "orcl18" (CHAR)
DEFINE _USER           = "SYS" (CHAR)
DEFINE _PRIVILEGE      = "AS SYSDBA" (CHAR)
DEFINE _SQLPLUS_RELEASE = "1803000000" (CHAR)   in 18C 

_o_version="Oracle Database 18c Enterprise Edition Release 18.0.0.0.0 - Production



-- set heading off feedback off 
set linesize 300
col kill for a70
select 'ALTER SYSTEM CANCEL SQL '''||sid||','||serial#||',@'||inst_id||','|| sql_id||'''  ;' kill from GV$SESSION
-- select 'ALTER SYSTEM CANCEL SQL '''||sid||','||serial#||',@'||inst_id||'''  ;' kill from GV$SESSION
-- select 'ALTER SYSTEM CANCEL SQL '''||sid||','||serial#||',@'||inst_id||','|| NVL(sql_id,prev_sql_id)||'''  ;' kill from GV$SESSION
where 1=1
-- and username='USER_NAME'
-- and status = 'INACTIVE'
-- and type != 'BACKGROUND'
-- and USERNAME not in ( 'SYS' , 'SYSTEM' , 'DBSNMP' , 'SYSMAN' , 'OUTLN' , 'MDSYS' , 'ORDSYS' , 'EXFSYS' , 'DMSYS' , 'WMSYS' , 'CTXSYS' , 'ANONYMOUS' , 'XDB' , 'ORDPLUGINS' , 'OLAPSYS' , 'PUBLIC','WWV_FLOW_PLATFORM' ) 
and sql_id is not null ;

in other session !!! run this sql !!!!!
SQL> begin loop null; end loop; end;
  2  /


http://anuj-singh.blogspot.com/2014/01/what-is-sql-doing.html

select * from SYS.STMT_AUDIT_OPTION_MAP order by option#

what is sql doing .... ?

set linesize 300 pagesize 500
col sql_text for a70 wrap
select inst_id,sql_id,
DECODE(command_type,
1,'CREATE TABLE',
2,'INSERT',
3,'SELECT',
4,'CREATE CLUSTER',
5,'ALTER CLUSTER',
6,'UPDATE',
7,'DELETE',
8,'DROP CLUSTER',
9, 'CREATE INDEX',
10,'DROP INDEX',
11,'ALTER INDEX',
12,'DROP TABLE',
13,'CREATE SEQUENCE',
14,'ALTER SEQUENCE',
15,'ALTER TABLE',
16,'DROP SEQUENCE',
17,'GRANT OBJECT',
18,'REVOKE OBJECT',
19,'CREATE SYNONYM',
20,'DROP SYNONYM',
21,'CREATE VIEW',
22,'DROP VIEW',
23,'VALIDATE INDEX',
24,'CREATE PROCEDURE',
25,'ALTER PROCEDURE',
26,'LOCK',
27,'NO-OP',
28,'RENAME',
29,'COMMENT',
30,'AUDIT OBJECT',
31,'NOAUDIT OBJECT',
32,'CREATE DATABASE LINK',
33,'DROP DATABASE LINK',
34,'CREATE DATABASE',
35,'ALTER DATABASE',
36,'CREATE ROLLBACK SEG',
37,'ALTER ROLLBACK SEG',
38,'DROP ROLLBACK SEG',
39,'CREATE TABLESPACE',
40,'ALTER TABLESPACE',
41,'DROP TABLESPACE',
42,'ALTER SESSION',
43,'ALTER USER',
44,'COMMIT',
45,'ROLLBACK',
46,'SAVEPOINT',
47,'PL/SQL EXECUTE',
48,'SET TRANSACTION',
49,'ALTER SYSTEM',
50,'EXPLAIN',
51,'CREATE USER',
52,'CREATE ROLE',
53,'DROP USER',
54,'DROP ROLE',
55,'SET ROLE',
56,'CREATE SCHEMA',
57,'CREATE CONTROL FILE',
59,'CREATE TRIGGER',
60,'ALTER TRIGGER',
61,'DROP TRIGGER',
62,'ANALYZE TABLE',
63,'ANALYZE INDEX',
64,'ANALYZE CLUSTER',
65,'CREATE PROFILE',
66,'DROP PROFILE',
67,'ALTER PROFILE',
68,'DROP PROCEDURE',
70,'ALTER RESOURCE COST',
71,'CREATE MATERIALIZED VIEW LOG',
72,'ALTER MATERIALIZED VIEW LOG',
73,'DROP MATERIALIZED VIEW LOG',
74,'CREATE MATERIALIZED VIEW',
75,'ALTER MATERIALIZED VIEW',
76,'DROP MATERIALIZED VIEW',
77,'CREATE TYPE',
78,'DROP TYPE',
79,'ALTER ROLE',
80,'ALTER TYPE',
81,'CREATE TYPE BODY',
82,'ALTER TYPE BODY',
83, 'DROP TYPE BODY',
84,'DROP LIBRARY',
85,'TRUNCATE TABLE',
86,'TRUNCATE CLUSTER',
91,'CREATE FUNCTION',
92,'ALTER FUNCTION',
93,'DROP FUNCTION',
94,'CREATE PACKAGE',
95,'ALTER PACKAGE',
96,'DROP PACKAGE',
97,'CREATE PACKAGE BODY',
98,'ALTER PACKAGE BODY',
99,'DROP PACKAGE BODY',
100,'LOGON',
101,'LOGOFF',
102,'LOGOFF BY CLEANUP',
103,'SESSION REC',
104,'SYSTEM AUDIT',
105,'SYSTEM NOAUDIT',
106,'AUDIT DEFAULT',
107,'NOAUDIT DEFAULT',
108,'SYSTEM GRANT',
109,'SYSTEM REVOKE',
110,'CREATE PUBLIC SYNONYM',
111,'DROP PUBLIC SYNONYM',
112,'CREATE PUBLIC DATABASE LINK',
113,'DROP PUBLIC DATABASE LINK',
114,'GRANT ROLE',
115,'REVOKE ROLE',
116,'EXECUTE PROCEDURE',
117,'USER COMMENT',
118,'ENABLE TRIGGER',
119,'DISABLE TRIGGER',
120,'ENABLE ALL TRIGGERS',
121,'DISABLE ALL TRIGGERS',
122,'NETWORK ERROR',
123,'EXECUTE TYPE',
157,'CREATE DIRECTORY',
158,'DROP DIRECTORY',
159,'CREATE LIBRARY',
160,'CREATE JAVA',
161,'ALTER JAVA',
162,'DROP JAVA',
163,'CREATE OPERATOR',
164,'CREATE INDEXTYPE',
165,'DROP INDEXTYPE',
167,'DROP OPERATOR',
168,'ASSOCIATE STATISTICS',
169,'DISASSOCIATE STATISTICS',
170,'CALL METHOD',
171,'CREATE SUMMARY',
172,'ALTER SUMMARY',
173,'DROP SUMMARY',
174,'CREATE DIMENSION',
175,'ALTER DIMENSION',
176,'DROP DIMENSION',
177,'CREATE CONTEXT',
178,'DROP CONTEXT',
179,'ALTER OUTLINE',
180,'CREATE OUTLINE',
181,'DROP OUTLINE',
182,'UPDATE INDEXES',
183,'ALTER OPERATOR'
,command_type) command_type,
dbms_lob.substr ( sql_text, 4000, 1) sql_text from gv$sql where sql_text like '%loop null; end loop%';

INST_ID SQL_ID COMMAND_TYPE SQL_TEXT
---------- ------------- ---------------------------------------- ----------------------------------------------------------------------
1 fm8f3a57b1au4 PL/SQL EXECUTE begin loop null; end loop; end;





set linesize 300
col kill for a70
-- select 'ALTER SYSTEM CANCEL SQL '''||sid||','||serial#||',@'||inst_id||''' ;' kill from GV$SESSION
select 'ALTER SYSTEM CANCEL SQL '''||sid||','||serial#||',@'||inst_id||','|| sql_id||''' ;' kill from GV$SESSION
-- select 'ALTER SYSTEM CANCEL SQL '''||sid||','||serial#||',@'||inst_id||','|| NVL(sql_id,prev_sql_id)||''' ;' kill from GV$SESSION
where 1=1
-- and username='user'
-- and status = 'INACTIVE'
-- and type != 'BACKGROUND'
--and USERNAME not in ( 'SYS' , 'SYSTEM' , 'DBSNMP' , 'SYSMAN' , 'OUTLN' , 'MDSYS' , 'ORDSYS' , 'EXFSYS' , 'DMSYS' , 'WMSYS' , 'CTXSYS' , 'ANONYMOUS' , 'XDB' , 'ORDPLUGINS' , 'OLAPSYS' , 'PUBLIC','WWV_FLOW_PLATFORM' )
and sql_id is not null ;


KILL
----------------------------------------------------------------------
ALTER SYSTEM CANCEL SQL '268,52248,@1,fm8f3a57b1au4' ;



SQL> begin loop null; end loop; end;
2 /
begin loop null; end loop; end;
*
ERROR at line 1:
ORA-01013: user requested cancel of current operation

Oracle DBA

anuj blog Archive