Call now: 252-767-6166  
Oracle Training Oracle Support Development Oracle Apps

 
 Home
 E-mail Us
 Oracle Articles
New Oracle Articles


 Oracle Training
 Oracle Tips

 Oracle Forum
 Class Catalog


 Remote DBA
 Oracle Tuning
 Emergency 911
 RAC Support
 Apps Support
 Analysis
 Design
 Implementation
 Oracle Support


 SQL Tuning
 Security

 Oracle UNIX
 Oracle Linux
 Monitoring
 Remote s
upport
 Remote plans
 Remote
services
 Application Server

 Applications
 Oracle Forms
 Oracle Portal
 App Upgrades
 SQL Server
 Oracle Concepts
 Software Support

 Remote S
upport  
 Development  

 Implementation


 Consulting Staff
 Consulting Prices
 Help Wanted!

 


 Oracle Posters
 Oracle Books

 Oracle Scripts
 Ion
 Excel-DB  

Don Burleson Blog 


 

 

 


 

 

 
 

Extract SQL from Oracle

Oracle Database Tips by Donald BurlesonJanuary 14, 2013

Question: I want to extract a SQL statement so that I can add hints to the SQL.  I'm looking for a way to extract the full text of a SQL statement from a table into a flat file so that I can tune the SQL.  How do I extract a SQL statement into a file for tuning purposes?

Answer: First, we seek those tables that contain the sql_fulltext column:

col c1 format a28 Heading 'Table|name'
col c2 format a20 Heading 'SQL column|name'
col c3 format a20 Heading 

select
   lower(table_name)  c1,
   lower(column_name) c2,
   lower(data_type)   c3
from
   dba_tab_columns
where
   column_name like 'SQL%'
and
   data_type = 'CLOB'
order by
   c1
desc;

As we see, Oracle does not follow consistent naming standards, so sometimes we have to guess about the dictionary columns that will contain the SQL to be extracted.  The most popular tables for SQL extraction are highlighted in yellow.


Table SQL column
name name 
---------------------------- -------------------- -----
all_sqlset_statements        sql_text 
aud$                         sqlbind 
aud$                         sqltext 
dba_advisor_sqla_wk_stmts    sql_text 
dba_advisor_sqlw_stmts       sql_text 
dba_hist_sqltext             sql_text 
dba_sql_profiles             sql_text 
dba_sqlset_statements        sql_text 
flow_sqlarea                 sql_fulltext 
gv_$sql                      sql_fulltext 
gv_$sql_shared_memory        sql_fulltext 
gv_$sqlarea                  sql_fulltext 
gv_$sqlarea_plan_hash        sql_fulltext 
gv_$sqlstats                 sql_fulltext 
jirefreshsql$                sqltext 
sql$text                     sql_text 
user_advisor_sqla_wk_stmts   sql_text 
user_advisor_sqlw_stmts      sql_text 
user_sqlset_statements       sql_text 
v$sql                       sql_fulltext 
v$sql_shared_memory         sql_fulltext 
v$sqlarea                   sql_fulltext 
v$sqlarea_plan_hash         sql_fulltext 
v$sqlstats                  sql_fulltext 
wrh$_sqltext                 sql_text 
wri$_adv_sqlw_stmts          sql_text 

Once we have identified the table and the column that we want to do the extraction, we can write a query using the "set long:" command, and specify the table_name.  In this example, we extract all SQL that references with the authors table, and spool the SQL to a file called display_sql.lst:

set long 100000

spool display_sql.lst

select
   sql_fulltext
from
   v$sql
where
   lower(sql_fulltext) like lower('%AUTHORS%');

 

 
Get the Complete
Oracle SQL Tuning Information 

The landmark book "Advanced Oracle SQL Tuning  The Definitive Reference"  is filled with valuable information on Oracle SQL Tuning. This book includes scripts and tools to hypercharge Oracle 11g performance and you can buy it for 30% off directly from the publisher.

 

 

Burleson is the American Team

Note: This Oracle documentation was created as a support and Oracle training reference for use by our DBA performance tuning consulting professionals.  Feel free to ask questions on our Oracle forum.

Verify experience! Anyone considering using the services of an Oracle support expert should independently investigate their credentials and experience, and not rely on advertisements and self-proclaimed expertise. All legitimate Oracle experts publish their Oracle qualifications.

Errata?  Oracle technology is changing and we strive to update our BC Oracle support information.  If you find an error or have a suggestion for improving our content, we would appreciate your feedback.  Just  e-mail:  

and include the URL for the page.


                    









Burleson Consulting

The Oracle of Database Support

Oracle Performance Tuning

Remote DBA Services


 

Copyright © 1996 -  2017

All rights reserved by Burleson

Oracle ® is the registered trademark of Oracle Corporation.

Remote Emergency Support provided by Conversational

 

 

��  
 
 
Oracle Training at Sea
 
 
 
 
oracle dba poster
 

 
Follow us on Twitter 
 
Oracle performance tuning software 
 
Oracle Linux poster