RE: Using ALL_CONS_COLUMN view inside a function

  • From: <Joel.Patterson@xxxxxxxxxxx>
  • To: <hammerl@xxxxxxxxxxxxxxx>, <oracle-l@xxxxxxxxxxxxx>
  • Date: Tue, 28 Aug 2007 08:02:41 -0400

Here is a function that does the same thing.   I always wanted an
opinion about it verses other ways.... Not just for concatenating column
names, but 'anything'.

I was wondering about efficiency, speed etc.   I have never traced it or
compared it.

Note: The function is inside comments /* */   There are two version of
the select statement that calls it,  (The second call 'is' different).

(I changed from 'user' to 'all' because of other related return emails
to your question... but the 'all' version does not account for 'owner'
etc... so edit the SELECT to suit your purposes).
 
/***********************************************************************
***
************************************************************************
***
This query utilized the function 'join' which must exist and is listed
below.
************************************************************************
**/
/*
create or replace function join
(
    p_cursor sys_refcursor,
    p_del varchar2 := ','
) return varchar2
is
    l_value   varchar2(32767);
    l_result  varchar2(32767);
begin
    loop
        fetch p_cursor into l_value;
        exit when p_cursor%notfound;
        if l_result is not null then
            l_result := l_result || p_del;
        end if;
        l_result := l_result || l_value;
    end loop;
    return l_result;
end join;
*/

set linesize 2000
set sqlcase upper
set heading off
set verify off
set feedback off

select join(cursor(select decode(rownum,1,'('||COLUMN_NAME,COLUMN_NAME)
columns
from all_tab_columns where table_name = '&table_name')) || ')' from
dual;

set sqlcase mixed
set heading on
set feedback on
set verify on

********************************************************
column columns format a30
set sqlcase upper
set heading off
set feedback off
select decode(rownum,1,'('||COLUMN_NAME||',',COLUMN_NAME||',') columns
from all_tab_columns where table_name = '&table_name'
order by 1;

set heading on
set feedback on
set sqlcase mixe

********************************************************

Joel Patterson
Database Administrator
joel.patterson@xxxxxxxxxxx
x72546
904  727-2546

-----Original Message-----
From: oracle-l-bounce@xxxxxxxxxxxxx
[mailto:oracle-l-bounce@xxxxxxxxxxxxx] On Behalf Of Brett Hammerlindl
Sent: Monday, August 27, 2007 10:32 PM
To: oracle-l@xxxxxxxxxxxxx
Subject: Using ALL_CONS_COLUMN view inside a function

I hope someone can help me sort out something that makes no sense to me.

I have written an Oracle function that returns a VARCHAR2 (see below)
You can see it has a cursor for a select of rows from the
ALL_CONS_COLUMN view. 

The function works fine when I run with p_owner set to the current user,

but I have hit a snag when I put in other owners. 

Here is an example when I run my function with parameters of 'SYS' 
and 'REGISTRY_PK', it returns a NULL string because no rows are found. 
BUT when I run this select, I get 2 rows returned.
  Select * from ALL_CONS_COLUMNS
   Where owner = 'SYS' and constraint_name = 'REGISTRY_PK'

When I hit this problem, I looked for the simplest case I could find
that had a problem. It is based on the statement.
  select count(*) cc from all_tables where owner = 'SYS'

The value returned inside a function is 27 while the query returns 703.

This is an Oracle 10g database. I am only using example with SYS as
owner 
since others can see if they get the same results. I had this problem 
with p_owner set other users as well.

Does anyone know what is going on?

How do I get a function to return a VARCHAR2 list the column names?

Thank you for the help, Brett

-- this function generates a string to use in a SQL query
-- the string concatenates all columns of constraint
-- in order to have a single varchar to match
CREATE OR REPLACE FUNCTION concatenateConstraintColumns(p_owner

VARCHAR2,
 
p_constraint_name 
VARCHAR2)
  RETURN VARCHAR2 IS
  v_column VARCHAR2(40);
  v_sql    VARCHAR2(1000);
  v_join   VARCHAR2(12) := ' || ''|'' || ';
  cursor column_cursor is
    select *
      from all_cons_columns
     where owner = p_owner
       and constraint_name = p_constraint_name
     order by position;
BEGIN
  for column in column_cursor loop
    v_column := column.column_name;
    if (column.position = 1) then
      v_sql := v_column;
    else
      v_sql := v_sql || v_join || v_column;
    end if;
  end loop;
  return v_sql;
END concatenateConstraintColumns;




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


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


Other related posts: