RE: What are the differences of v$sqltext, v$sqlarea, v$sql

  • From: "Herring Dave - dherri" <Dave.Herring@xxxxxxxxxx>
  • To: <karlarao@xxxxxxxxx>, <oracle-l@xxxxxxxxxxxxx>
  • Date: Thu, 2 Jul 2009 11:09:41 -0500

Checking V$FIXED_VIEW_DEFINITION, you can see that V$SQLAREA is based off of 
x$kglcursor_child_sqlid, V$SQL is off x$kglcursor_child, and V$SQLTEXT is off 
x$kglna.  I may be way off on this, but I believe pure DDL is not a cursor, 
which is why it won't be found in X$ cursor tables.  Check with a CTAS vs. a 
plain CREATE TABLE ... (field ...).  CTAS uses a cursor and would be found in 
all the X$ sql tables.  A plan CREATE TABLE won't.

Again, I may be way off on the reason why, but hopefully the above helps 
explain a little of what you're seeing.

David C. Herring  | DBA, Acxiom Automotive

630-944-4762 office | 630-430-5988 cell | 630-944-4989 fax
1501 Opus Pl | Downers Grove, IL, 60515 | U.S.A. | www.acxiom.com


________________________________________
From: oracle-l-bounce@xxxxxxxxxxxxx [mailto:oracle-l-bounce@xxxxxxxxxxxxx] On 
Behalf Of Karl Arao
Sent: Wednesday, July 01, 2009 11:06 PM
To: oracle-l@xxxxxxxxxxxxx
Subject: What are the differences of v$sqltext, v$sqlarea, v$sql

Hi Guys, 


Weird scenario, when I'm looking for TRUNCATE statement, I can see it in 
V$SQLTEXT .... but I can't see it in V$SQLAREA and V$SQL


select * from v$sqltext where upper(sql_text) like '%TRUNCATE%TEST3%'; -- 
returns the truncate statement

select * from v$sqlarea 
where sql_id = 'dfwz4grz83d6a'
where upper(sql_text) like '%TRUNCATE%'; -- no rows

select * from v$sql 
where sql_id = 'dfwz4grz83d6a'
where upper(sql_text) like '%TRUNCATE%'; -- no rows



So to have a more readable ASH... I joined it with SQL_TEXT so I can clearly 
see the TRUNCATE statement on the samples... 

set lines 3000
select substr(sa.sql_text,1,500) txt, a.sample_id, a.sample_time, a.session_id, 
a.session_serial#, a.user_id, a.sql_id,
       a.sql_child_number, a.sql_plan_hash_value, 
       a.sql_opcode, a.plsql_object_id, a.service_hash, a.session_type,
       a.session_state, a.qc_session_id, a.blocking_session,
       a.blocking_session_status, a.blocking_session_serial#, a.event, 
a.event_id,
       a.seq#, a.p1, a.p2, a.p3, a.wait_class,
       a.wait_time, a.time_waited, a.program, a.module, a.action, a.client_id
from gv$active_session_history a, gv$sqltext sa 
where a.sql_id = sa.sql_id
and session_id = 126




So my question is, what are the differences of v$sqltext, v$sqlarea, v$sql?  
Any ideas?  :)



- Karl Arao
http://karlarao.wordpress.com
***************************************************************************
The information contained in this communication is confidential, is
intended only for the use of the recipient named above, and may be legally
privileged.

If the reader of this message is not the intended recipient, you are
hereby notified that any dissemination, distribution or copying of this
communication is strictly prohibited.

If you have received this communication in error, please resend this
communication to the sender and delete the original message or any copy
of it from your computer system.

Thank You.
****************************************************************************

--
//www.freelists.org/webpage/oracle-l


Other related posts: