Tip

Simple query formatter

This script is useful for ad-hoc queries with numerous select list items within SQL*Plus. It formats the output as one column_name = column_value per line. Normally, the display would show many heading lines and then some data, making it difficult to line up columns with their values. It is most useful for displaying data from a small number of rows of a table/view that has numerous columns where the SQL*Plus output is difficult to read. It's handy for debugging data problems and for ad-hoc queries.

Limitations: Works only with Oracle built-in datatypes (varchar,number,date etc) and returns at most 4000 bytes of column value. Since it returns clob type, is not appropriate for querying large number of rows as it may not be able to allocate enough temp space.

Usage: From SQL*Plus, 'set long' and 'longchunksize' large enough for the estimated size of data returned. Example:

SQL> select pageview('select * from user_tables where
table_name=''MYTABLE''') from dual;

Example output:

/*
 --Row 1
TABLE_NAME                = MYTABLE
TABLESPACE_NAME           = MYTABLESPACE
CLUSTER_NAME              =
IOT_NAME                  =
PCT_FREE                  = 10
PCT_USED                  = 40
INI_TRANS                 = 1
MAX_TRANS                 = 255
INITIAL_EXTENT            = 13127680
NEXT_EXTENT               = 9818112
MIN_EXTENTS               = 1
MAX_EXTENTS               = 249
PCT_INCREASE              = 50
FREELISTS         

    Requires Free Membership to View

= 1 FREELIST_GROUPS = 1 LOGGING = YES BACKED_UP = N NUM_ROWS = BLOCKS = EMPTY_BLOCKS = AVG_SPACE = CHAIN_CNT = AVG_ROW_LEN = AVG_SPACE_FREELIST_BLOCKS = NUM_FREELIST_BLOCKS = DEGREE = 1 INSTANCES = 1 CACHE = N TABLE_LOCK = ENABLED SAMPLE_SIZE = LAST_ANALYZED = PARTITIONED = NO IOT_TYPE = TEMPORARY = N SECONDARY = N NESTED = NO BUFFER_POOL = DEFAULT ROW_MOVEMENT = DISABLED GLOBAL_STATS = NO USER_STATS = NO DURATION = SKIP_CORRUPT = DISABLED MONITORING = NO CLUSTER_OWNER = DEPENDENCIES = DISABLED /*

Here's the script. It was developed on 9i, but will work on versions supporting CLOB datatype and dynamic PL/SQL (dbms_sql package).

 chndl integer;
 descTab dbms_sql.desc_tab2;
 colCnt integer;
 outVal varchar2(4000);
 numrows number;
 rowCnt integer := 0;

 -- newline character
 nl varchar2(1) := '
';

 maxColNameLen pls_integer := 0;

 retval clob ;

begin

 -- First we validate that this is a select statement
 if upper(ltrim(sqlstmt)) not like 'SELECT%' then
  raise_application_error(-20001,'Not a SELECT statement');
 end if;

 -- open a cursor
 chndl := dbms_sql.open_cursor;

 -- parse the select statement
 dbms_sql.parse(chndl,sqlstmt,dbms_sql.NATIVE);

 -- now describe columns
 dbms_sql.describe_columns2(chndl,colCnt,descTab);

 -- set length for each column
 for i in 1..colCnt loop

  -- get the max length of column name in query for display format purposes
  if descTab(i).col_name_len > maxColNameLen then
   maxColNameLen := descTab(i).col_name_len;
  end if;

  -- Dates are set to size 7, we'll use 12 but may need changed based on
default date output format
  if descTab(i).col_type=12 then -- date datatype
   dbms_sql.define_column(chndl,i,descTab(i).col_name,12);
  else -- all others use max len of column

dbms_sql.define_column(chndl,i,descTab(i).col_name,descTab(i).col_max_len);
  end if;

 end loop;

 -- Now execute the sql
 numrows := dbms_sql.execute(chndl);

 -- fetch each row and format column_name = column_value, one per line
 loop
  if dbms_sql.fetch_rows(chndl) > 0 then
   rowCnt := rowCnt+1;

   -- Use the row number as a separator between row displays
   retVal := retVal||nl||' --Row '||rowCnt||nl;

   -- get column values
   for i in 1..colCnt loop
    dbms_sql.column_value(chndl,i,outVal);
   -- concat <column_name> = <column_value>
    retval := retval||rpad(descTab(i).col_Name,maxColNameLen)||' =
'||outVal||nl;
   end loop;

  else
   exit;
  end if;

 end loop;

 dbms_sql.close_cursor(chndl);

 return(retval);

 exception when others then
  if dbms_sql.is_open(chndl) then dbms_sql.close_cursor(chndl); end if;
  return(sqlerrm);

end;

For More Information

  • Feedback: E-mail the editor with your thoughts about this tip.
  • More tips: Hundreds of free Oracle tips and scripts.
  • Tip contest: Have an Oracle tip to offer your fellow DBAs and developers? The best tips submitted will receive a cool prize -- submit your tip today!
  • Ask the Experts: Our SQL, database design, Oracle, SQL Server, DB2, metadata, and data warehousing gurus are waiting to answer your toughest questions.
  • Forums: Ask your technical Oracle questions--or help out your peers by answering them--in our active forums.
  • Best Web Links: Oracle tips, tutorials, and scripts from around the Web.

This was first published in October 2002

There are Comments. Add yours.

 
TIP: Want to include a code block in your comment? Use <pre> or <code> tags around the desired text. Ex: <code>insert code</code>

REGISTER or login:

Forgot Password?
By submitting you agree to receive email from TechTarget and its partners. If you reside outside of the United States, you consent to having your personal data transferred to and processed in the United States. Privacy
Sort by: OldestNewest

Forgot Password?

No problem! Submit your e-mail address below. We'll send you an email containing your password.

Your password has been sent to:

Disclaimer: Our Tips Exchange is a forum for you to share technical advice and expertise with your peers and to learn from other enterprise IT professionals. TechTarget provides the infrastructure to facilitate this sharing of information. However, we cannot guarantee the accuracy or validity of the material submitted. You agree that your use of the Ask The Expert services and your reliance on any questions, answers, information or other materials received through this Web site is at your own risk.