Skip to Main Content

Breadcrumb

Question and Answer

Connor McDonald

Thanks for the question, PRATTY.

Asked: January 17, 2001 - 5:34 pm UTC

Last updated: August 17, 2022 - 4:07 am UTC

Version: ORACLE 8i 8.1.5

Viewed 100K+ times! This question is

You Asked

Hi Tom,
I want to declare multiple cursors based on the values
passed through a procedure ie, only where conditions of the
cursors will change. The body of the procedure is
same for all the cursors.
Pls. suggegst a solution.

Thanking you,

regards,
Pratty.


and Tom said...

Updated May 4th, 2009

See this link for a superior approach:

http://asktom.oracle.com/pls/asktom/f?p=100:11:0::::P11_QUESTION_ID:1669972300346534908




Sounds like a good use of REF CURSORS to me.  Lets say you wanted to build a generic routine that would look at the inputs passed to it and build a WHERE clause for each NON-NULL parameter passed.  This would result in a large number of statically defined cursors so we'll use a ref cursor instead.  

I'll demonstrate below.  I'll write a write that will print out some EMP data.  This routine will take upto 3 inputs to constrain the result set.  I want to have upto 8 different cursors possible here

o 1 with NO where clause (all inputs null)
o 3 with a single predicate
o 3 with "pairs" of predicate conditions
o 1 with all three predicate conditions

Additionally, since the use of BIND VARIABLES is one of the MOST important things in programming Oracle -- I'll want to make sure I use them as well.  This will be trickly since I don't know if I'll have 0, 1, 2, or 3 of them until runtime.  I'll use an application context to solve that problem.

Here is a sample implementation:


ops$tkyte@ORA8I.WORLD> create or replace context MY_CTX using MY_PROCEDURE
  2  /

Context created.

<b>That created our application context and bound it to our yet to be created procedure "MY_PROCEDURE".  Note that only MY_PROCEDURE will be able to set values in this context.  See 
http://asktom.oracle.com/~tkyte/article2/index.html
for more info on application contexts and their use</b>

ops$tkyte@ORA8I.WORLD> create or replace 
     procedure p ( p_str in varchar2 )
  2  is
  3     l_str   long := p_str || chr(10);
  4     l_piece long;
  5     n       number;
  6  begin
  7      loop
  8          exit when l_str is null;
  9          n := instr( l_str, chr(10) );
 10          l_piece := substr( l_str, 1, n-1 );
 11          l_str   := substr( l_str, n+1 );
 12             loop
 13                exit when l_piece is null;
 14                dbms_output.put_line( substr( l_piece, 1, 
                                                        250 ) );
 15                l_piece := substr( l_piece, 251 );
 16          end loop;
 17     end loop;
 18  end;
 19  /

Procedure created.


<b>P is just a little procedure I use to print things out nicer then dbms_output would.  I use it below to dump the dynamically generated query so we can see what was built for each execution.  It is not really relevant to the example, just part of the demonstration...</b>

ops$tkyte@ORA8I.WORLD> create or replace
  2  procedure my_procedure( p_ename   in varchar2 default NULL,
  3                          p_hiredate  in date default NULL,
  4                          p_sal       in number default NULL)
  5  as
  6      type rc is REF CURSOR;
  7  
  8      l_cursor rc;
  9      l_query  varchar2(512)
 10               default 'select * from emp where 1 = 1 ';
 11  
 12      cursor l_template is select * from emp;
 13      l_rec  l_template%rowtype;
 14  

<b>Here I use what I call a "TEMPLATE" cursor.  I like to use these with my ref cursors.  I use them to define a record to fetch into.  Here, in this simple example, I could have skipped it and just defined l_rec as EMP%rowtype -- but I wanted to show how this would work if you didn't select * from a single table but had many columns from many tables.  This just helps me create a nice record.  The template query ONLY has a SELECT and a FROM.  I never put a WHERE clause on it (even when joining) since I never use it any where.  I just use it to get the default datatypes, names and so on for a record definition right below it.</b>

 15  begin
 16  
 17      if ( p_ename is NOT NULL ) then
 18          dbms_session.set_context( 'MY_CTX', 'ENAME',
 19                                    '%'||upper(p_ename)||'%');
 20          l_query := l_query ||
 21               ' and ename like
 22                 sys_context( ''MY_CTX'', ''ENAME'' ) ';
 23      end if;
 24  

<b>for each input -- i'm inspecting it to see if it is non-null.  If it is, I add to the where clause and set the value in the context.  Notice how in the where clause -- I always use the SYS_CONTEXT function.  I NEVER put the literal value in to the query (that would be very bad and would trash the shared pool -- very extremely important to use bind variables).  Note also the use of '' to get a single ' into the where clause!</b>

 25      if ( p_hiredate is NOT NULL ) then
 26          dbms_session.set_context( 'MY_CTX', 'HIREDATE',
 27                    to_char(p_hiredate,'yyyymmddhh24miss'));
 28          l_query := l_query ||
 29                ' and hiredate >
 30                    to_date(
 31                       sys_context( ''MY_CTX'',
 32                                    ''HIREDATE'' ),
 33                       ''yyyymmddhh24miss'') ';
 34      end if;

<b>Note here how I am careful to preserve the date and time component -- if necessary!  Always wrap the sys_context in a TO_DATE call if you are comparing to a DATE to avoid implicit conversions in the query at runtime!</b>


 35  
 36      if ( p_sal is NOT NULL ) then
 37          dbms_session.set_context( 'MY_CTX', 'SAL', p_sal);
 38          l_query := l_query ||
 39                ' and sal >
 40                   to_number(
 41                       sys_context( ''MY_CTX'',
 42                                    ''SAL'' )
 43                             ) ';
 44      end if;
 45  

<b>Same caveat for the NUMBER here.  Use TO_NUMBER to avoid IMPLICIT conversions</b>

 46      p( l_query );
 47  
 48      open l_cursor for l_query;
 49  
 50      loop
 51          fetch l_cursor into l_rec;
 52          exit when l_cursor%notfound;
 53  
 54          dbms_output.put_line( l_rec.ename || ',' ||
 55                                l_rec.hiredate || ',' ||
 56                                l_rec.sal );
 57      end loop;
 58  
 59      close l_cursor;
 60  end;
 61  /

Procedure created.


<b> and that is it.  I now have a routine that will open 1 of 8 possible different cursors.  Here is a small test run just to see how it works</b>

ops$tkyte@ORA8I.WORLD> 
ops$tkyte@ORA8I.WORLD> exec my_procedure
select * from emp where 1 = 1
SMITH,17-dec-1980 00:00:00,800
ALLEN,20-feb-1981 00:00:00,1600
WARD,22-feb-1981 00:00:00,1250
JONES,02-apr-1981 00:00:00,2975
MARTIN,28-sep-1981 00:00:00,1250
BLAKE,01-may-1981 00:00:00,2850
CLARK,09-jun-1981 00:00:00,2450
SCOTT,09-dec-1982 00:00:00,3000
KING,17-nov-1981 00:00:00,5000
TURNER,08-sep-1981 00:00:00,1500
ADAMS,12-jan-1983 00:00:00,1100
JAMES,03-dec-1981 00:00:00,950
FORD,03-dec-1981 00:00:00,3000
MILLER,23-jan-1982 00:00:00,1300
KING,,5

PL/SQL procedure successfully completed.

ops$tkyte@ORA8I.WORLD> exec my_procedure( p_ename => 'a' )
select * from emp where 1 = 1  and ename like
sys_context( 'MY_CTX', 'ENAME' )
ALLEN,20-feb-1981 00:00:00,1600
WARD,22-feb-1981 00:00:00,1250
MARTIN,28-sep-1981 00:00:00,1250
BLAKE,01-may-1981 00:00:00,2850
CLARK,09-jun-1981 00:00:00,2450
ADAMS,12-jan-1983 00:00:00,1100
JAMES,03-dec-1981 00:00:00,950

PL/SQL procedure successfully completed.

ops$tkyte@ORA8I.WORLD> exec my_procedure( p_sal => 1000 )
select * from emp where 1 = 1  and sal >
to_number(
sys_context( 'MY_CTX',
'SAL' )
)
ALLEN,20-feb-1981 00:00:00,1600
WARD,22-feb-1981 00:00:00,1250
JONES,02-apr-1981 00:00:00,2975
MARTIN,28-sep-1981 00:00:00,1250
BLAKE,01-may-1981 00:00:00,2850
CLARK,09-jun-1981 00:00:00,2450
SCOTT,09-dec-1982 00:00:00,3000
KING,17-nov-1981 00:00:00,5000
TURNER,08-sep-1981 00:00:00,1500
ADAMS,12-jan-1983 00:00:00,1100
FORD,03-dec-1981 00:00:00,3000
MILLER,23-jan-1982 00:00:00,1300

PL/SQL procedure successfully completed.

ops$tkyte@ORA8I.WORLD> exec my_procedure( p_hiredate => add_months(sysdate,-240) )
select * from emp where 1 = 1  and hiredate >
to_date(
sys_context( 'MY_CTX',
'HIREDATE' ),
'yyyymmddhh24miss')
ALLEN,20-feb-1981 00:00:00,1600
WARD,22-feb-1981 00:00:00,1250
JONES,02-apr-1981 00:00:00,2975
MARTIN,28-sep-1981 00:00:00,1250
BLAKE,01-may-1981 00:00:00,2850
CLARK,09-jun-1981 00:00:00,2450
SCOTT,09-dec-1982 00:00:00,3000
KING,17-nov-1981 00:00:00,5000
TURNER,08-sep-1981 00:00:00,1500
ADAMS,12-jan-1983 00:00:00,1100
JAMES,03-dec-1981 00:00:00,950
FORD,03-dec-1981 00:00:00,3000
MILLER,23-jan-1982 00:00:00,1300

PL/SQL procedure successfully completed.

ops$tkyte@ORA8I.WORLD> exec my_procedure( p_ename => 'a', p_sal => 2000 )
select * from emp where 1 = 1  and ename like
sys_context( 'MY_CTX', 'ENAME' )  and sal >
to_number(
sys_context( 'MY_CTX',
'SAL' )
)
BLAKE,01-may-1981 00:00:00,2850
CLARK,09-jun-1981 00:00:00,2450

PL/SQL procedure successfully completed.

ops$tkyte@ORA8I.WORLD> 

 

Rating

  (408 ratings)

Is this answer out of date? If it is, please let us know via a Comment

Comments

Lots of help, I was adrift on reference cursors

Harrison, August 12, 2001 - 10:28 am UTC

Thanks for the help. The example, as often happens with
your answers, taught me more than one thing (three or
four, in fact). I started reading another response, followed a link to this and picked up several things that
will help (the page linked here was a '1=1' question, which
was also interesting).

Helena Markova, August 20, 2001 - 5:23 am UTC


Most advanced

andrew, August 28, 2001 - 12:38 pm UTC

Interesting, I never knew about sys_context() in this context :) It certainly is a common scenario and this approach overcomes having a separate query for each permutation.

Srinivas Atreya, August 30, 2001 - 5:25 am UTC

Simply Brilliant, never knew about the context stuff...--:)

Is there a way to avoid giving the select multiple number of times

Nag, November 06, 2001 - 2:46 pm UTC

function test ( params ) is

rc refcursor;

lv_rc rc;

begin


open rc for

Select column list

from

(select same set of columns
from same set of from same tables
where different conditions
union

select same set of columns
from same set of from same tables
where different conditions
union

select same set of columns
from same set of from same tables
where different conditions
union
select
same set of columns
from same set of from same tables
where different conditions)

return rc;


end test;

Tom, as you see iam having to give the same select with different where clause again and again, what is the best way to handle this.

The objective is to reduce the code

Tom Kyte
November 06, 2001 - 3:26 pm UTC

It is called an OR

select same set of columns
from same set of tables
where (condition1) or (condition2) or (condition3)


It could be somewhat more efficient then a UNION as well as:

A union B union C

is really

distinct( sort( a + b + c ) )

you'll skip a non-necessary sort/distinct step.

(please ask only relevant followups in this space. I only answered this one cause its sort of related and I really like the example -- by touching it, it goes back onto the front page. I'm not answering the other one about counting commas -- it has nothing to do with the original question at all)



Dynamic cursor

William, November 07, 2001 - 9:03 am UTC

This is really helpful and handy too. But I would like to know the advantage of using context over building the predicate dynamically eg.

l_query := l_query || ' and empname like '''||p_ename||'''';

Thanks



Tom Kyte
November 07, 2001 - 6:30 pm UTC

Get my book -- its all about bind variables.

Bind variables are SO crucial, so important -- you MUST use them.

If you do something like:

for i in 1 .. 1000
loop
execute immediate 'insert into t values ( ' || i || ')';
end loop;

90%, yes 90%, of your time will be spent parsing. If you on the other hand:

execute immediate 'insert into t values ( :x )' using I;

you will spend a significantly less amount of time parsing. And if you just:

insert into t values ( i );

you'll spend almost NO time.


Parsing (soft and hard) latches the library cache. A latch is a lock by any other name. You are serializing operations by over parsing. it will limit your scalability, decrease your performance and you will FAIL if you do not use bind variables!



A non dynamic alternative

Jeroen, November 08, 2001 - 10:52 pm UTC

Hi Tom,

I always appreciate your answers, and I really appreciate the techniques you are demonstrating.
But looking at this specific example, where the input parameters and table are hardcoded, I was wondering whether the construct underneath would not solve the problem as well.


create or replace
procedure my_procedure( p_ename in varchar2 default NULL,
p_hiredate in date default NULL,
p_sal in number default NULL)
as

cursor c_emp
(b_ename varchar2
,b_hiredate date
,b_sal number
)
is
select *
from emp e
where e.ename = decode( b_ename
,null, e.ename
, b_ename
)
and e.hiredate = decode( b_hiredate
,null, e.hiredate
, b_hiredate
)
and e.sal = decode( b_sal
,null, e.sal
, b_sal
);

begin
for l_recin c_emp
(b_ename => p_ename
,b_hiredate => p_hiredate
,b_sal => p_sal
)
loop
dbms_output.put_line( l_rec.ename || ',' ||
l_rec.hiredate || ',' ||
l_rec.sal );
end loop;
end;
/

Tom Kyte
November 09, 2001 - 10:15 am UTC

Yes it would HOWEVER, in the real world it would not perform very well at all.

You see -- your approach would result in a query that could only be optimized by using a FULL TABLE SCAN in all cases -- indexes and other techniques would be ruled out!

The dynamic approach has the advantage that the optimizer has a good query to work with -- it'll get queries like:

select * from emp where ename = :bv;

select * from emp where hiredate = :bv1 and sal = :bv2;

It can optimize each one (and it'll only do that once and then stash the plan away for reuse later). Each one can and probably will have a different plan. One query can use an index on ENAME, the other on SAL or HIREDATE or SAL & HIREDATE.

Your query obviates the use of indexes in 100% of the cases (even with an function based index -- there would be no chance).


I would definitely 100% go for dynamic SQL in this case.


How to reset complete context

Frank, November 09, 2001 - 8:07 am UTC

Great example.
Is it possible to reset the entire context any other way then looping through list_context output?


Tom Kyte
November 09, 2001 - 10:26 am UTC

Well, you could iterate over the rows in SESSION_CONTEXT as well (it is a table with your current context values).

But yes, you'll be iterating over something to reset the entire context -- the API only does entry by entry.

CURSOR

Niloufar, December 10, 2001 - 6:42 pm UTC

Tom,

Thank you for your complete and helpful answer.

In another article I had asked you for your help in writing a procedure that can handle a list of elements as the parameter to the procedure to be used in a "where clause". Could that same technique (creating a type in SQL and using the in_list function, etc...) be used in "my_procedure" to create the "where clause"?

Here is what I am trying to do:

- create procedure
my_procedure(clause1_par IN varchar2(30),
clause2_par IN varchar2(10))

where clause1_par and clause2_par can be a list

- In the body of my_procedure I'd like to be able to create the sql statement:

select * from table_name
where field1 in (clause1_par)
and field2 in (clause2_par)

Couple of questions:

1- Can I still use the in_list function in "my_procedure" to receive a list of elements as parameter?

2- If I have two parameters and both are lists, how can I figure out where the first parameter's elements end and the next parameter's list start? Is this doable?

Thanks again for all your help. Please let me know if my question is not clear.



Can this be applied to Execute Immediate?

Tim Glasgow, March 14, 2002 - 5:26 am UTC

I expect that this can be applied to execute immediate also and it does not necessarily only apply to ref_cursors.

Tom Kyte
March 14, 2002 - 8:25 am UTC

Yes, you can use this as a method to "bind" any SQL insert/update/delete/select (and in 9i MERGE) command.

Problems with dbms_session

Tim Glasgow, March 14, 2002 - 9:12 am UTC

I am getting the following error when I use dbms_session.set_context. The user has been granted execute privileges from sys and still this doesn't make any difference. A contributor from RevealNet said:

"...they can run DBMS_SESSION OK (the error message indicates that they are in it), but they're not allowed to do whatever it is that they are asking to do via DBMS_SESSION"

ERROR at line 1:
ORA-01031: insufficient privileges
ORA-06512: at "SYS.DBMS_SESSION", line 58
ORA-06512: at "PROP.AGENTPROPERTYREPORTS", line 269
ORA-06512: at line 2


Tom Kyte
March 14, 2002 - 10:21 am UTC

The contributor from revealnet is dead on.

A context is bound to a plsql procedure/function or package.  You cannot call dbms_session directly.  It works like this:

ops$tkyte@ORA817DEV.US.ORACLE.COM> create or replace context my_ctx USING my_procedure
  2  /

Context created.

ops$tkyte@ORA817DEV.US.ORACLE.COM> 
ops$tkyte@ORA817DEV.US.ORACLE.COM> create or replace procedure my_procedure( p_name in varchar2, p_value in varchar2 )
  2  as
  3  begin
  4          dbms_session.set_context( 'my_ctx', p_name, p_value );
  5  end;
  6  /

Procedure created.

ops$tkyte@ORA817DEV.US.ORACLE.COM> 
ops$tkyte@ORA817DEV.US.ORACLE.COM> exec dbms_session.set_context( 'my_ctx', 'hello', 'world' );
BEGIN dbms_session.set_context( 'my_ctx', 'hello', 'world' ); END;

*
ERROR at line 1:
ORA-01031: insufficient privileges
ORA-06512: at "SYS.DBMS_SESSION", line 62
ORA-06512: at line 1


ops$tkyte@ORA817DEV.US.ORACLE.COM> select sys_context( 'my_ctx', 'hello' ) sc from dual;

SC
--------------------


ops$tkyte@ORA817DEV.US.ORACLE.COM> 
ops$tkyte@ORA817DEV.US.ORACLE.COM> exec my_procedure( 'hello', 'world' );

PL/SQL procedure successfully completed.

ops$tkyte@ORA817DEV.US.ORACLE.COM> select sys_context( 'my_ctx', 'hello' ) sc from dual;

SC
--------------------
world



So, I would have to assume that when you created the context, you did not specify USING PROP.AGENTPROPERTYREPORTS -- hence that piece of code cannot set the context.

 

At last

Tim Glasgow, March 14, 2002 - 10:47 am UTC

Tom, thanks very much that was the problem. Well done!

..obviously creating the context in a sqlplus session under the same user doesn't work as I had done this before I attempted to execute the package.procedure
(i.e. SQL> create or replace context MY_CTX using prop.AgentPropertyReports;

Operation 177 succeeded.)

I also had the create context in my procedure a built it using exec immediate, but as you spotted didn't have the user prefix before the package.

Thanks very much for your help.
Tim



 

Tom Kyte
March 14, 2002 - 10:53 am UTC

Suggestion -- upgrade your SQLPlus version if you want to use new features. Funky things can happen if you use an older sqlplus against a newer db -- for example, sqlplus isn't recognizing "CREATE OR REPLACE CONTEXT" as a SQL command properly -- that tells me you are using the v8.0 or before sqlplus against 8i. Some commands might not work AT ALL.

Followup

Tim Glasgow, March 15, 2002 - 9:37 am UTC

Hi Tom,
I found application context to be absolutely superb, but I've run into a problem with using 'IN' in my dynamic query.

----------------------------------------------------
dbms_session.set_context( 'MY_CTX', 'estateagentid', pc_estate_agent_id_in);

 sql_stmt := sql_stmt || ' and ea.estateagentid IN sys_context( ''MY_CTX'', ''estateagentid'')';

----------------------------------------------------

If I do pc_estate_agent_id_in => '139' -- its OK
If I do pc_estate_agent_id_in => '139,44' -- error:

SQL>  @unit_tests/properties/test_all_nulls
Input truncated to 1 characters
139,44
hi1
BEGIN
*
ERROR at line 1:
ORA-01722: invalid number
ORA-06512: at "PROP.AGENTPROPERTYREPORTS", line 343
ORA-06512: at line 2

I know it's something to do with the quotes or the comma and have tried every combination of adding quotes to the context attribute and the parameter.

 

Tanel Hiir, March 28, 2002 - 6:51 am UTC

Tom,

Oracle8i Application Developer's Guide - Fundamentals Chapter 11:

<blockquote>
Fine-grained access control with application context was designed to handle static applications; that is, those for which the security attributes contained within application contexts are static within the user sessions. In other words, the feature is best used for applications in which the user logs in, his application context is set for the session, and the context does not change until the user logs off. This design principle enables application context to be highly scalable, because many users can share the same fully-parsed, optimized statement.
</blockquote>

Does it apply only to DBMS_RLS?
Or does it influence dynamic SQL with sys_contex use also?


Tom Kyte
March 28, 2002 - 5:06 pm UTC

They are only taking about DBMS_RLS there.

Excellent technique -- now I have a ton of tuning work to do!!!

Keith Miller, April 03, 2002 - 5:07 pm UTC

This works great.

However, I notice that the number of parse_calls for these are equal the number of executions for each distinct query in v$sqlarea. There are no invalidations for any of the distinct queries.

I have my dynamic call wrapped in dbms_utility.get_time statements for timing. The response time I get looks as if the statements are not being reparsed. The initial time the query is run the response is 7 hsecs, subsequent excutions respond in 2 hsecs.

Is there anything I can do to reduce the parse_calls for these dynamic queries?

Tom Kyte
April 03, 2002 - 6:28 pm UTC

REF CURSORS must be parsed each time -- by definition. They cannot be cached (they are potentially DIFFERENT with each execute!)

search this site for session_cached_cursors, that'll help you.

They are being SOFT PARSED, much better then a hard parse -- much worse then no parse or a session_cached_cursor hit.


More on cursors...

Andre Whittick Nasser, April 04, 2002 - 10:38 am UTC

I have 2 questions on cursors. Maybe you are able to clarify them, both in 9i:

1) CURSOR_SHARING = SIMILAR -> The Oracle on-line books and the Oracle University books (the only ones on 9i I really trust) are rather reticent on this feature. They only say things like "the CBO examines the statement for safe (?) literals" or "the CBO uses statistics on available structures, like histograms". I know bind variable values are assigned only after execution plan generation, so the CBO is not aware of these values. Also, I know how histograms are used to find out about the selectivity of column values. Can you please explain briefly how "similar" statements are treated ?

2) Could you elaborate a bit on "cached" execution plans ?

Thanks!

Tom Kyte
April 04, 2002 - 1:14 pm UTC

SIMILAR
Causes statements that may differ in some literals, but are otherwise identical,
to share a cursor, unless the literals affect either the meaning of the statement or the degree to which the plan is optimized.


What this means is that we will take a query such as:


select * from emp where sal > 100


and turn that into "select * from emp where sal > :x". We will decide IF that bind variable is "safe" -- that is, if changing the literal value could affect the plan. In many cases -- it could (eg: full tablescan for sal > 100, index range scan for sal > 10000). Hence, similar queries will not share the plan.

On the other hand, a query like:

select * from emp where empno = 5555;

that would be deemed "safe", that is, regardless of the literal value used, the query plan will be the same (index unique scan on the empno index). Hence the queries

select * from emp where empno = 1
select * from emp where empno = 2

will be "similar" and will use shared sql. The determination of whether a bind variable would be "safe" or not is made before the optimizer kicks in.

Also, in 9i, the optimizer will "peek" at binds before generating the optimized plan, this is new. So -- the optimizer does have access to the binds *the first time it opimizes a statement* (but obviously not so on subsequent parses since they just reuse the optimized plan that already exists)


a cached execution plan is what is stored in the shared pool. it is the "shared sql".

Cached execution plans and V$SQL_PLAN

Andre Whittick Nasser, April 04, 2002 - 2:15 pm UTC

Thanks for the explanation on CURSOR_SHARING=SIMILAR. The quirk I was missing was the "peek" at binds by the CBO in 9i. Interesting.

Sorry for asking you about cached execution plans. It's a misnomer, in fact. It's being described as being some new feature of 9i. Of course it's not -- in essence at least. It's the name Oracle is giving to the possibility of viewing the ACTUAL, "stored" execution plan, as opposed to that generated by EXPLAIN PLAN. EXPLAIN PLAN is an ESTIMATE of what will be executed. On the other hand, the new V$_SQL_PLAN shows the real, previously executed plan.

From the Performance Guide:

"
V$SQL_PLAN

This view provides a way of examining the execution plan for cursors that were recently executed.

The information in this view is very similar to the output of an EXPLAIN PLAN statement. However, EXPLAIN PLAN shows a theoretical plan that can be used if this statement were to be executed, whereas V$SQL_PLAN contains the actual plan used. The execution plan obtained by the EXPLAIN PLAN statement can be different from the execution plan used to execute the cursor, because the cursor might have been compiled with different values of session parameters (for example, HASH_AREA_SIZE).
"

Thanks !

Tom Kyte
April 04, 2002 - 3:28 pm UTC

Ahh -- but a$sql_plan is just showing you the cached plan from the shared pool -- it's not really new (the cached plan), the ability to "see it" is all that is new here.

That's what I meant...

Andre Whittick Nasser, April 04, 2002 - 4:56 pm UTC


Cached execution plans...

Andre Whittick Nasser, April 04, 2002 - 5:14 pm UTC

That's what I meant ! I have an Oracle document titled "Cached Execution Plans". At first, I didn't know what was new about it, then I asked you. Later I saw that what was new wasn't the cached stuff -- of course. The view was new.

You know what's interesting ?

V$SQL has a new column, PLAN_HASH_VALUE. Like with HASH_VALUE, which you can use to compare 2 sql texts, you can use PLAN_HASH_VALUE to know if the plan has changed for a specific cursor. In fact, you can do both to compare cursors plans:

Either...

- compare V$SQL_PLAN rows or

- compare V$SQL.PLAN_HASH_VALUE column values

If you do:

column id format 999 newline
column operation format a20
column operation format a20
column options format a15
column object_name format a22 trunc
column optimizer format a3 trunc

SELECT id
, lpad (' ', depth) || operation operation
, options
, object_name
, optimizer
, cost
FROM V$SQL_PLAN
WHERE hash_value = 2446703096
AND address = '80E3A1D8'
START WITH id = 0
CONNECT BY
( prior id = parent_id
AND prior hash_value = hash_value
AND prior child_number = child_number
)
ORDER SIBLINGS BY id, position;

ID OPERATION OPTIONS OBJECT_NAME OPT COST
---- -------------------- --------------- ---------------------- --- ----------
0 SELECT STATEMENT CHO
1 SORT ORDER BY 6
2 NESTED LOOPS 4
3 HASH JOIN 3
8 TABLE ACCESS BY INDEX ROWID ORDERS 1
9 INDEX RANGE SCAN ORDERS_PK 2
4 TABLE ACCESS BY INDEX ROWID ORDERS_LINE_ITEM 1
5 INDEX RANGE SCAN ORDERS_LINE_ITEM_PK 2
6 TABLE ACCESS BY INDEX ROWID ORDERS_STATUS 1
7 INDEX RANGE SCAN ORDERS_STATUS_PK 2

10 rows selected.

Then you have the plan for that specific child cursor. Here, we have only one child cursor.

Thanks !

Another approach using package variables

James Turner, April 05, 2002 - 9:29 am UTC

Seems like you could achieve the same results using package variables. What advantage is there to the application context approach over this alternative?

Tom Kyte
April 05, 2002 - 9:44 am UTC

You cannot do that in a dynamically opened ref cursor.

open cursor for 'select * from t where x = pkg.variable';

won't work. you could code:

open cursor for 'select * from t where x = pkg.function_returning_variable';

but that can be highly "non-performant". sys_context is treated just like a bind variable -- using sys_context the code:

open cursor for 'select * from t where x = sys_context( ''n'', ''v'' )';

is treated as:

open cursor for 'select * from t where x = :bind_variable';



Dyanmic Attribute?

Robert Boyle, July 25, 2002 - 10:35 am UTC

Hi Tom,
Thanks for this most useful piece of coding! I was wondering is there anyway of creating the attribute in dbms_session.set_context dynamically? Reason I am asking is that we are getting a string containing various words to search a field for and I am building the sql using this procedure (along with checkin a dozen other parameters) and using multiple likes.

eg: l_query := l_query || ' and description like sys_context(''MY_CTX'', ''DESCRIPTION'')';

can DESCRIPTION be made dynamically to be DESCRIPTION1, DESCRIPTION2 etc...or am I going about this the wrong way? Should I use intermedia, or should I limit the number of key words available for a search thus I would know the limit required in the query?

Cheers
Robert

Tom Kyte
July 25, 2002 - 10:26 pm UTC

Not sure what you are asking here?

Dynamic Attribute

Robert, July 26, 2002 - 5:10 am UTC

Sorry, never was the best at explaining myself!

First of all let me explain the parameter I receive. It will contain several keywords to search a description field for, seperated by a space.

'myword yourword ourword anotherword'

I use the code you supplied to check whether it is null or not and whether I need to append it to my dynamic query to run against the table. (there are other parameters too that are checked to see if they are null).

if ( p_keywords is NOT NULL ) then

This is where I am unsure of the best way to do things. I need to get these keywords and do a like comparison on each of them against the description field. So I create a loop and get the keyword into a local variable (l_keyword) and then set the context:

dbms_session.set_context( 'MY_CTX', 'DESCRIPTION', '%'||l_keyword||'%');

My problem stems here. I will not know how many keywords there might be and my understanding is that if I assign l_keyword to the 'DESCRIPTION' attribute, I will over write each l_keyword until I get to the final one in my loop. So that my l_query would have:
' and description like sys_context(''MY_CTX'', ''DESCRIPTION'')

several times in the query and therefore only check a like for the same word n amount of times.

Therefore, I was wondering if

a) we should limit the amount of keywords (this I do at the moment) so that I can loop and assign to attribute 'DESCRIPTION1', 'DESCRIPTION2' etc

b) we can create the attribute 'DESCRIPTION' || l_keyword_count on the fly (ie have 'DESCRIPTON1', 'DESCRIPTION2' created dynamically in the code)

or

c)should we abandon using this and go for Intermedia, the desciption field is a varchar2(2000) and so not that large.

Thanks for your help.
Robert

Tom Kyte
July 26, 2002 - 7:01 am UTC

Ok, you'll have to use the approach you are currently using -- description1, description2 and so on -- making a unique name for each.

You can do this dynamically on the fly -- the variable names in the context are just strings. You make them up as you go along.


Intermedia won't do "%word%" searches -- the leading % is a bad thing, hard problem to solve. cannot be solved with an index.

Robert, July 26, 2002 - 11:12 am UTC

Hi Tom,

I tried creating the attribute dynamically...but maybe I am going about it wrong? Below is my code that loops and appends to the query:

WHILE l_description IS NOT NULL LOOP

l_delimiter := INSTR(l_description, ' ');
l_length := LENGTH(l_description);
IF l_delimiter = 0 THEN
l_delimiter := l_length;
ELSE
NULL;
END IF;

l_desc_part := SUBSTR(l_description, 1, l_delimiter);
l_desc_count := l_desc_count + 1;
l_desc_context := 'DESCRIPTION' || l_desc_count;

dbms_session.set_context('MY_CTX', l_desc_context, '%'||l_desc_part||'%');
l_query := l_query || ' and description like sys_context(''BUGTRACK_CTX'', l_desc_context)';
END LOOP;

When I run this I get :

ERROR at line 1:
ORA-00904: invalid column name
ORA-06512: at "ROBERT.MY_PKG", line 216
ORA-06512: at line 43

Any ideas?

Thanks
Robert

Tom Kyte
July 28, 2002 - 3:00 pm UTC

when you build this query -- it'll be:

select .... and description like
sys_context('BUGTRACK_CTX', l_desc_context)


well, l_desc_context isn't known in the query!

what you need is:

l_query := l_query ||
' and description like sys_context(''BUGTRACK_CTX'', ''' ||
l_desc_context || ''' )';


so your where clause reads:

select .... and description like
sys_context('BUGTRACK_CTX','DESCRIPTION1')

you need to concatenate in the VALUE of l_desc_context, not the word l_desc_context!


Dynamic Attribute

Robert, July 29, 2002 - 4:07 am UTC

Brilliant, thanks Tom. It all seems so obvious now!

question on the followup for -- a non dynamic alternative

john, August 12, 2002 - 12:13 pm UTC

Hi Tom,

i just would like to know that why the index is not used in the following query. because we have not used any function on on ename or sal or hiredate(which are on left hand side)

select *
from emp e
where e.ename = decode( b_ename
,null, e.ename
, b_ename
)
and e.hiredate = decode( b_hiredate
,null, e.hiredate
, b_hiredate
)
and e.sal = decode( b_sal
,null, e.sal
, b_sal
);

i have used a query that get all the records for which either start date falls in 2002 or end date falls in like below:

select * from my_table where strt_date = to_date(to_char(strt_dt,'DDMM')||'2002','DDMMYYYY')
OR end_date = to_date(to_char(strt_dt,'DDMM')||'2002','DDMMYYYY')

now my question is will the above query not use the index on strt_date and end_date.

if no, can this below query use the index:

select * from my_table where strt_date >= to_date('01012002','DDMMYYYY')
OR end_date <= to_date('31122002','DDMMYYYY')


Tom Kyte
August 12, 2002 - 1:50 pm UTC

you most certainly did use a function on ename, sal and hiredate!!!!


where e.ename = function_of( ...., e.name, .... )
^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^^

right there!

How could one use an index on:

where x = decode( :bv, null, x, :bv );


the decode can return a different value for each and every row!!!! if :bv is NULL that decode is NOT a constant and you can only use an index when we have a constant!

You want to use a technique like:

(well, I was going to cut and paste the url for this question here but then I noticed you already found the answer!!!!)

use the technique above.


you want to query like this:

select *
from t
where strt_date between to_date('01-jan-2002')
and to_date('01-jan-2003')-1/24/60/60
or end_date between to_date('01-jan-2002')
and to_date('01-jan-2003')-1/24/60/60


your approach *applies a function* to the column -- to_date(to_char(strt_dt,'DDMM')||'2002','DDMMYYYY') is potentially different for each and every row -- no way to use an index with that (well, you could use a function based index but that would be the wrong solution here, just use between like I did)


Another way?

Darko Egersdorfer, August 13, 2002 - 7:54 am UTC

Can't you achieve the same (without using sys_context), creating dummy WHERE condition if passed parameter has null value. So, you will always use the same number of bind variables in USING clause.
if ( p_ename is NOT NULL ) then
l_query := l_query ||
' and ename like ''%''||:p_ename||''%''';
else
l_query := l_query ||
' and 1 = DECODE(:p_ename,NULL,1,1)';
end if;

...

open l_cursor for l_query USING p_ename,p_hiredate,p_sal;

(You can always TO_CHAR and TO_DATE date parameters using the same format)


Tom Kyte
August 13, 2002 - 5:07 pm UTC

sure, but if you've gone to all of that work -- you might just as well not include the predicate anyway. Why add an extra decode if you need not? Also, sys context lets you do it when you have no clue how many binds you might have.

Yes, you can do it like this.
I would myself use sys_context.


create context privillege

john, August 13, 2002 - 11:56 am UTC

tom,
when i try creating the context, i get an error

create or replace CONTEXT my_ctx using my_procedure

ORA-01031: insufficient privileges

is that enough if i have create or replace context privellege or do i also need to have execute privilege on dbms_session.set_context as well.

please suggest

Tom Kyte
August 13, 2002 - 5:25 pm UTC

ops$tkyte@ORA817DEV.US.ORACLE.COM> grant create any context to scott;

Grant succeeded.

is what you are missing. 

contexts vs. predicates using short-circuited OR

Bill Coulam, August 13, 2002 - 2:10 pm UTC

I've never seen that context stuff used before. Very cool. I can't wait to dig into it more.

Up until this point, whenever I've had a query that made use of bind variables that were possibly empty, I've used the following approach, depending on the short-circuiting nature of "OR" in PL/SQL:

CURSOR c_mytab (<parmlist>) IS
SELECT m.* FROM mytab m
WHERE (ln_id IS NULL
OR
m.myid = ln_id)
AND (ls_msg IS NULL
OR
m.myval = ls_msg)
...
;
BEGIN
OPEN CURSOR c_mytab(<parmlist>);
...etc.

It looks and feels a little "lumpy", but it seems like less code and hassle than the context stuff.

So far, the only drawback we've experienced is aesthetic. When adapted to Dynamic SQL, there are two slots for each variable/parameter, e.g.

EXECUTE IMMEDIATE 'SELECT ...
' USING in_id, in_id, is_msg, is_msg;

That's not so hot.

Can you think of anything wrong with using the OR in this way?

bill coulam

Tom Kyte
August 20, 2002 - 4:18 pm UTC

the optimized query plan from this OR stuff where you say

where ( bind_variable IS NULL or table.column = bind_variable )

will be really bad compared to the approach above which results in a finely tuned query.

The optimizer looks at that OR and says -- hmm, maybe we will do the compare, maybe no -- no index for you (it would not be able to use an index on table.column effectively whereas my approach will)

short circuited or

A reader, September 03, 2002 - 1:17 pm UTC

but tom,

when i used the OR approach, i see optimizer using the index when the bind variable is null. i gave a sample query like this

select * from emp where (null is null or empno = 1)

then i saw full table scan on emp

now when i modify the query:

select * from emp where (1 is null or empno = 1)

then i saw the index is being used on that..

do you still suggest that this or approach result bad optimizer plan. i don't understand why?


Tom Kyte
September 03, 2002 - 2:34 pm UTC

You did NOT use any bind variables.  That is why.  consider:

ops$tkyte@ORA920.US.ORACLE.COM> create table emp as select * from scott.emp;

Table created.

ops$tkyte@ORA920.US.ORACLE.COM> alter table emp add constraint emp_pk primary key(empno);

Table altered.

ops$tkyte@ORA920.US.ORACLE.COM> 
ops$tkyte@ORA920.US.ORACLE.COM> variable x number
ops$tkyte@ORA920.US.ORACLE.COM> 
ops$tkyte@ORA920.US.ORACLE.COM> set autotrace traceonly explain
ops$tkyte@ORA920.US.ORACLE.COM> 
ops$tkyte@ORA920.US.ORACLE.COM> exec :x := null

PL/SQL procedure successfully completed.

ops$tkyte@ORA920.US.ORACLE.COM> select * from emp where ( :x is null or empno = :x );

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE
   1    0   TABLE ACCESS (FULL) OF 'EMP'



ops$tkyte@ORA920.US.ORACLE.COM> exec :x := 1

PL/SQL procedure successfully completed.

ops$tkyte@ORA920.US.ORACLE.COM> select * from emp where ( :x is null or empno = :x );

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE
   1    0   TABLE ACCESS (FULL) OF 'EMP'



ops$tkyte@ORA920.US.ORACLE.COM> 
ops$tkyte@ORA920.US.ORACLE.COM> select * from emp where (null is null or empno = 1);

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE
   1    0   TABLE ACCESS (FULL) OF 'EMP'



ops$tkyte@ORA920.US.ORACLE.COM> select * from emp where (1 is null or empno = 1);

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE
   1    0   TABLE ACCESS (BY INDEX ROWID) OF 'EMP'
   2    1     INDEX (UNIQUE SCAN) OF 'EMP_PK' (UNIQUE)



ops$tkyte@ORA920.US.ORACLE.COM> 


Bind variable = FULL SCAN.
Hard coded literals = new plan for every query = Maybe full scan, maybe not. 

short-circuited or

A reader, September 03, 2002 - 3:53 pm UTC

thanks so much tom

Privilege problem when calling DBMS_SESSION

Mike Stacey-Gee, September 04, 2002 - 7:30 am UTC

An elegant solution but I'm receiving an error whenever I access DBMS_SESSION despite running as a user with DBA privilege (8i v8.1.7)

variable c REFCURSOR;
exec MSCR_PAYABLEEMPTIES( :c, 'O');

ERROR at line 1:
ORA-01031: insufficient privileges
ORA-06512: at "SYS.DBMS_SESSION", line 58
ORA-06512: at "MIS.MSCR_PAYABLEEMPTIES", line 16
ORA-06512: at line 1

Attached is a subset of the procedure that triggers the error:

CREATE OR REPLACE PACKAGE "MIS"."P_REF_CURSOR" is
type ret_ref_cursor is ref cursor;
end p_ref_cursor;

CREATE OR REPLACE CONTEXT MSCR_CTX_PAYABLEEMPTIES USING MSCR_PAYABLEEMPTIES;

CREATE OR REPLACE PROCEDURE "MIS"."MSCR_PAYABLEEMPTIES" (
Result_Cursor IN OUT p_ref_cursor.ret_ref_cursor,
Direction IN VARCHAR2 DEFAULT NULL,
EndDate IN VARCHAR2 DEFAULT NULL
)
AS
l_query varchar2(9999);
BEGIN

l_query := 'SELECT DIRECTION,TRADE,VESSELCODE,VOYAGENUMBER,LOADPORTCODE,' ||
'DISCHPORTCODE,EQUIPMENTTYPE,NOOFCONTAINERS,TEUS,CONTRTEUS ' ||
'FROM MISFLATMVOYAGE WHERE COMMODITYCODE = ''RE00''';

-- Check whether a direction parameter has been passed
-- N.B. If passed from the web reports module it will contain '' instead of NULL to
-- indicate a blank parameter

IF ( Direction IS NOT NULL ) AND ( Direction <> '''' ) THEN
dbms_session.set_context('MSCR_CTX_PAYABLEEMPTIES', 'DIRECTION', Upper(Direction));
l_query := l_query ||
' AND DIRECTION = sys_context(''MSCR_CTX_PAYABLEEMPTIES'', ''DIRECTION'' )';
END IF;

open Result_Cursor FOR l_query;

END MSCR_PAYABLEEMPTIES;

Tom Kyte
September 04, 2002 - 8:49 am UTC

Well, it doesn't have anything to do with DBA/not DBA.

You can execute dbms_session -- the 1031 is coming from the fact that "MIS"."MSCR_PAYABLEEMPTIES" is not able to set the context MSCR_CTX_PAYABLEEMPTIES.

I notice your procedure and package have "MIS".  on them.  But the context does not.  If you ran this script as a user OTHER THEN "MIS", then the context can only be set by that SCHEMA.MSCR_PAYABLEEMPTIES -- not by MIS.MSCR_PAYABLEEMPTIES;

Perhaps that is it.  Do a select * from dba_context and make sure the SCHEMA is in fact MIS.

Here is a small test case showing the "issue"

ops$tkyte@ORA817DEV.US.ORACLE.COM> drop context MSCR_CTX_PAYABLEEMPTIES;

Context dropped.

ops$tkyte@ORA817DEV.US.ORACLE.COM> drop user a cascade;

User dropped.

ops$tkyte@ORA817DEV.US.ORACLE.COM> 
ops$tkyte@ORA817DEV.US.ORACLE.COM> create user a identified by a;

User created.

ops$tkyte@ORA817DEV.US.ORACLE.COM> 
ops$tkyte@ORA817DEV.US.ORACLE.COM> grant create session to a
  2  /

Grant succeeded.

ops$tkyte@ORA817DEV.US.ORACLE.COM> 
ops$tkyte@ORA817DEV.US.ORACLE.COM> 
ops$tkyte@ORA817DEV.US.ORACLE.COM> CREATE OR REPLACE CONTEXT MSCR_CTX_PAYABLEEMPTIES USING MSCR_PAYABLEEMPTIES;

Context created.

ops$tkyte@ORA817DEV.US.ORACLE.COM> 
ops$tkyte@ORA817DEV.US.ORACLE.COM> 
ops$tkyte@ORA817DEV.US.ORACLE.COM> CREATE OR REPLACE  PROCEDURE "A"."MSCR_PAYABLEEMPTIES"
  2  AS
  3  BEGIN
  4      dbms_session.set_context('MSCR_CTX_PAYABLEEMPTIES', 'DIRECTION', 'x' );
  5  END MSCR_PAYABLEEMPTIES;
  6  /

Procedure created.

ops$tkyte@ORA817DEV.US.ORACLE.COM> 
ops$tkyte@ORA817DEV.US.ORACLE.COM> @connect a/a
ops$tkyte@ORA817DEV.US.ORACLE.COM> set termout off
a@ORA817DEV.US.ORACLE.COM> REM GET afiedt.buf NOLIST
a@ORA817DEV.US.ORACLE.COM> set termout on
a@ORA817DEV.US.ORACLE.COM> 
a@ORA817DEV.US.ORACLE.COM> 
a@ORA817DEV.US.ORACLE.COM> exec MSCR_PAYABLEEMPTIES
BEGIN MSCR_PAYABLEEMPTIES; END;

*
ERROR at line 1:
ORA-01031: insufficient privileges
ORA-06512: at "SYS.DBMS_SESSION", line 62
ORA-06512: at "A.MSCR_PAYABLEEMPTIES", line 4
ORA-06512: at line 1


a@ORA817DEV.US.ORACLE.COM> 
a@ORA817DEV.US.ORACLE.COM> @connect /
a@ORA817DEV.US.ORACLE.COM> set termout off
ops$tkyte@ORA817DEV.US.ORACLE.COM> REM GET afiedt.buf NOLIST
ops$tkyte@ORA817DEV.US.ORACLE.COM> set termout on
ops$tkyte@ORA817DEV.US.ORACLE.COM> 
ops$tkyte@ORA817DEV.US.ORACLE.COM> 
ops$tkyte@ORA817DEV.US.ORACLE.COM> CREATE OR REPLACE CONTEXT MSCR_CTX_PAYABLEEMPTIES USING A.MSCR_PAYABLEEMPTIES;

Context created.

ops$tkyte@ORA817DEV.US.ORACLE.COM> 
ops$tkyte@ORA817DEV.US.ORACLE.COM> @connect a/a
ops$tkyte@ORA817DEV.US.ORACLE.COM> set termout off
a@ORA817DEV.US.ORACLE.COM> REM GET afiedt.buf NOLIST
a@ORA817DEV.US.ORACLE.COM> set termout on
a@ORA817DEV.US.ORACLE.COM> 
a@ORA817DEV.US.ORACLE.COM> 
a@ORA817DEV.US.ORACLE.COM> exec MSCR_PAYABLEEMPTIES

PL/SQL procedure successfully completed.

a@ORA817DEV.US.ORACLE.COM> 

<b>
See, until the context is bound to the "A" schema - the procedure owned by "A" cannot set it.</b>
 

using the same context field value in two queries

A reader, September 09, 2002 - 6:40 pm UTC

can we use the same context field in different queries

like

dbms_session.set_context('my_ctx','ename','john');
execute immediate
'select count(1) from emp where ename = sys_context('my_ctx','ename')';

open p_ref_cur for 'select * from emp where ename = sys_context('my_ctx','ename')';

is the above possible? i am getting an error ' invalid column name

Tom Kyte
September 09, 2002 - 8:07 pm UTC

sure you can but you have to write the code right!


to get a single quote in a string you have to use two quotes.

'select count(1) from emp where ename = sys_context(''my_ctx'',''ename'')';

assigning context to a procedure

ramu, September 30, 2002 - 2:55 pm UTC

can i assign the same context to more than one procedure or it should always be used in assigning to a single proc?

can i do like :

create or replace context MY_CTX using MY_PROCEDURE1;

create or replace context MY_CTX using MY_PROCEDURE2;

Tom Kyte
October 01, 2002 - 9:28 am UTC

you can do that but only the last one COUNTS.

Only one procedure or PACKAGE (<<<=== thats how to allow more then one proceudre access) at a time.

ref cursor

Mo, December 24, 2002 - 3:28 pm UTC

Tom:

In the example above you build the WHERE clause dynamically. How about if I want to build the columns in the SQL itself. The situation I have is:

I have a table for organization and a table for warehouse.
One org may have one or more warehouse. I want to run a inventory report to do total count for items for org and break it also by warehouse. I have a function that cimputes total quantity. But now after figuring out which org user belongs to, I want to build my SQL statment based on how many warehouses he has. let us say he has one warehouse only then it will be:

FOR x in (SELECT item,compute_qty(org,item) qty1 from stock_items)
LOOP
htp.p(item);
htp.p(qty1);

If there are two warehouses then I want:
FOR x in (SELECT item,compute_qty(org,item) qty1, compute_qty(warehouse1,item) qty2,
compute_qty(warehouse2,item) qty3
from stock_items)
LOOP
htp.p(item);
htp.p(qty1);
htp.p(qty2);
htp.p(qty3);
etc....

IS THIS SOMETHING TO BE DONE USING REF CURSORS in PL/SQL?

Thank you,


Tom Kyte
December 24, 2002 - 4:26 pm UTC

not with ref cursors - they fetch into a known set of plsql variables or a fixed record (eg: the OUTPUT of a ref cursor is known at compile in if plsql is fetching)

using dbms_sql -- trivial. Just look at the listprint code, or the cellsprint code in owa_util.

cursor

mo, December 24, 2002 - 4:50 pm UTC

Tom:

Thanks. I will look into dbms_sql even though I remember you used to always say use "Execute immediate instead".

1. getcode owa_util.listprint does not work. Do i have to login as SYS.

THank you,

Tom Kyte
December 24, 2002 - 5:53 pm UTC

Nope -- I never said that. Read my chapter on dynamic sql in "Expert one on one" -- there I show you when you will use native dynamic sql and when you will use dbms_sql.

This is one of the cases that clearly falls into dbms_sql.

getcode uses USER_SOURCE. You would have to be logged in as the owner of the package in order to use it or

select text from dba_source where name = 'OWA_UTIL' and type = 'PACKAGE BODY' order by line

I do it the following way when all the predicates are varchars

Bala, December 26, 2002 - 4:10 am UTC

This one is regarding the original posting.
define a cursor for select * from tbl where col_v1 like nvl(v1,'%'||v1||'%') and col_v2 like nvl(v2,'%'||v2||'%') and ..... so on.
Any 'Danger Will Robinson's here?

Tom Kyte
December 26, 2002 - 11:49 am UTC

If you always put % on the front and back -- you can do that since indexes would be pretty much useless where and the only plan will be a full scan (eg: the plan will not change from query to query).

This solution above is good when you want:


select * from t where x = 5;

to be optimized DIFFERENTLY then


select * form t where y like 'hello%';

In this case -- we might make use of an index on X for one and Y on another. That will NOT work with you do something like:


where x = nvl(bind_var_x,x)
and y like nvl(bind_var_y,y)



ref cursor

mo, January 13, 2003 - 3:14 pm UTC

Tom:

Would this also work instead of using ref cursor. let us say you have three inputs and you want to build AND SQL statement.

FOR x in (SELECT * from table where country=p_country
intersect
SELECT * from table where state=p_state
intersect
SELECT * from table where city=p_city)
LOOP
...
END LOOP;

Tom Kyte
January 13, 2003 - 4:10 pm UTC

time it -- tell me what happens when you specify:

USA
CA
San Francisco


USA -- returns lots of records (lots of people in that country)
CA -- returns a good percentage of those (lots of people in CA)
San Francisco -- returns the least number, but still sizable

Then, we put them together -- and figure out what is in all three and sort distinct it (which may materially change the answer - sort/distinct)...


Or, we can just

select * from table where .....;




context

mo, January 13, 2003 - 4:53 pm UTC

Tom:

You are right. The interesect can be slow for large tables.

However, when I implement the context solution: I get

SQL> create or replace context proc_ctx using proc_list;
create or replace context pi_ctx using pi_list
*
ERROR at line 1:
ORA-01031: insufficient privileges

I asked DBA to grant context for dev account and he says it is not simple. Is it difficult? is in it a simple grant?

Thank you, 

Tom Kyte
January 13, 2003 - 7:12 pm UTC

They should create the context for you. It is that simple.


If they won't do it, ctl-f and search for

Another way?

on this page.



set context

mo, January 15, 2003 - 5:06 pm UTC

Tom:

To build a clause as :

where col1 between p_from_col1 and p_to_col1

Can you do in one if statement?

or you have to implement two ifs and two set_context.

Thanks,

Tom Kyte
January 16, 2003 - 8:09 am UTC

think about it... this is just writing code mo, just writing code. Seems like it is one if, two sets doesn't it?

if ( p_from_col1 is not null and p_to_col1 is not null )
then
dbms_session.set_ctx( 'my_ctx', 'p_from_col1', p_from_col1 );
dbms_session.set_ctx( 'my_ctx', 'p_from_col2', p_from_col2 );
l_query := l_query || ' and col1 between sys_context .......';
end if;


doesn't make any sense to have two ifs - if either of to or from is null - it would not make sense to query on them. You obviously need two context values -- hence you need two calls to set context.

context

mo, January 16, 2003 - 9:23 am UTC

Tom

Thanks. What I meant is that whether I can assign two values in one statement of dbms_session.set_ctx but obviously I can not.

THanks a lot,

count

mo, January 22, 2003 - 10:03 am UTC

Tom:

For the above solution ,let us say you want to count records before you open ref cursor. I used execute immediate and it does not work.

execute immediate 'select count(*) from '||l_query||' into l_cnt';

Is not this valid?

Tom Kyte
January 22, 2003 - 10:11 am UTC

why -- you do know the answer is immediately different - that count is obsolete right away....

I hate that idea more then anything -- well, maybe not more then not using bind variables.... but you get my point.


reread:

</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:3489618933902

and read:

http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:4456921593765 <code>

to get my opinion on that very bad, wasteful, slow, wrong practice.


count

mo, January 22, 2003 - 10:47 am UTC

Tom:

I see you point which makes sense. However, the count is accurate when that user started his search.

Are you also against the idea of doing a count for a the record subset (10 records) (if pagesize is 10) after a page is created to determine whether to plae a NEXT button or not?

Are you always in favor of displaying a blank page?

Thanks,

Tom Kyte
January 22, 2003 - 11:02 am UTC

no it isn't -- the instant after you start that query that count can change.


do it the way you want. what I am in favor of isn't really relevant here is it?

Don't do a count, just overfetch by one record to see if there is a next page.

variable output parameters

Sujata, January 27, 2003 - 4:47 pm UTC

building a procedure for advanced search...
This procedure will accept parameters from a web page...and returns a recordset to the web page.
The output parameters will be what ever user wants..and user will also build the where clause...for example "Employee Name like 'To%'.
The no of tables invloved are known...but the joins are built dynamically....
This is how I approached:

PROCEDURE EMP_ADVANCED_SEARCH (pCOL LONG := null,
pRELATION LONG := null,
pVALUE LONG := null,
pSELECT_COL LONG := null,
C_OUT_CUR OUT T_REFCUR)



AS

vSQL LONG;
vSELECT LONG;
vFROM LONG;
vWHERE LONG;


BEGIN

vSELECT := pSELECT_COL;



VSQL := 'SELECT ' || vSELECT || CHR(10) ||
' FROM ' || vFROM || CHR(10) ||
' WHERE ' || vWHERE;


WRITE_A_STRING (VSQL);
OPEN C_OUT_CUR FOR VSQL;

END EMP_ADVANCED_SEARCH;




Here is a sample of values for parameters:
pCOL = 'ENAME,DEPT_NAME'
pRELATION = 'LIKE,='
pVALUE = '%TO%,10'
pSELECT_COL = 'EMPLID, DEPT, ENAME, SALARY'

pCOL, pRELATION, pVALUE ARE THE PARAMETER TO BUILD WHERE CLAUSE..BASED ON THE USER INPUT...
pSELECT_COL DESCRIBES THE COLUMNS THAT THE USER WANTS IN THE RECORDSET

vFROM, vWHERE CLAUSE WILL BE BUILT BASED ON pSELECT_COL,pCOL, pRELATION AND pVALUE
PARAMETERS.




QUESTION:
I am lost on building FROM and WHERE clause dynamically part...
Here is what I am imagining:
I will run pCOL and pSELECT_COL through loops..and will check the column_name
against SOME_TABLE to find the table name the column is in
and will keep adding
to the VFROM and VWHERE clause...and I will check before I add a join relationship to VWHERE
or a table to VFROM...to make sure that it hasn't been added before (instr function).

SOME_TABLE will have table_names, column_names
as two columns...and I will check the column names in pCOL and pSELECT_COL parameters against
this table.
In scott schema for example DEPTNO is in both tables EMP and DEPT.
but I think this custom table should have DEPTID reference only one time...so that
we will hit one or the other when we are looking for DEPTID column..to see what table does
it relate to..
We won't mention DEPT table in the from clause or where clause...unless DEPTNAME is mentioned
either in pCOL parameter or pSELECT_COL parameter.


Is there a better way to accomplish this?

Thanks.




sys_context not using index???

Paul, March 11, 2003 - 8:19 am UTC

Tom,

Can you explain the following, please? I'm very puzzled!

Oracle 8.1.7 - Customers has 4 million odd rows, indexed on postcode.
As per your book p716,  I have used sys_context when building up dynamic sql.
So why won't Oracle use the index when using sys_context when I'm using both OR and LIKE, yet it does when hard-coding the values (see below)?  It also works fine if I just use LIKE (no OR) with the sys_context statement.


SQL> select
  2  UPPER(sys_context('mycontext','postcode1'))||'%' postcode1,
  3  UPPER(sys_context('mycontext','postcode2'))||'%' postcode2
  4  from dual;

postcode1                       postcode2
------------------------------- ---------------------------------------
NT6 7EF%                        NT6 8AP%

SQL> set autotrace on
SQL> select cus_number from customers cus
  2  where cus.postcode like 'NT6 7EF%'
  3  or
  4  cus.postcode like 'NT6 8AP%';

CUS_NUMBER  
------------- 
3860001833844 
3860005094542 
3860005094543 
3860005094544 
3860002229221 
3860002229878 
3860002386195 
3860002386196 
3860002436754 
3860002436844 
0273000769335 
0273000638189 
0273000952026 
0273002199257 
0273002239570 
0273002446665 
0273000769334 

17 rows selected.


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=16 Card=16 Bytes=2064)
   1    0   CONCATENATION
   2    1     TABLE ACCESS (BY INDEX ROWID) OF 'CUSTOMERS' (Cost=4 Card=1 Bytes=129)
   3    2       INDEX (RANGE SCAN) OF 'CUS_PC_I' (NON-UNIQUE) (Cost=3 Card=1)
   4    1     TABLE ACCESS (BY INDEX ROWID) OF 'CUSTOMERS' (Cost=4 Card=1 Bytes=129)
   5    4       INDEX (RANGE SCAN) OF 'CUS_PC_I' (NON-UNIQUE) (Cost=3 Card=1)

Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
         25  consistent gets
          0  physical reads
          0  redo size
       4239  bytes sent via SQL*Net to client
        529  bytes received via SQL*Net from client
          8  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
         17  rows processed

SQL>  select * from customers cus
  2  where cus.postcode like UPPER(sys_context('mycontext','postcode1'))||'%'
  3  or
  4  cus.postcode like UPPER(sys_context('mycontext','postcode2'))||'%';

CUS_NUMBER  
------------- 
3860001833844 
3860005094542 
3860005094543 
3860005094544 
3860002229221 
3860002229878 
3860002386195 
3860002386196 
3860002436754 
3860002436844 
0273000769335 
0273000638189 
0273000952026 
0273002199257 
0273002239570 
0273002446665 
0273000769334 

17 rows selected.


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=28972 Card=545239 Bytes=70335831)
   1    0   TABLE ACCESS (FULL) OF 'CUSTOMERS' (Cost=28972 Card=545239 Bytes=70335831)


Statistics
----------------------------------------------------------
          0  recursive calls
         12  db block gets
     190893  consistent gets
     189129  physical reads
          0  redo size
       4242  bytes sent via SQL*Net to client
        617  bytes received via SQL*Net from client
          8  SQL*Net roundtrips to/from client
          3  sorts (memory)
          0  sorts (disk)
         17  rows processed
 

Tom Kyte
March 11, 2003 - 8:54 am UTC

what happens with:


variable x varchar2(20);
exec :x := 'NT6 7EF%';
variable y varchar2(20);
exec :y := 'NT6 8AP%';

select cus_number from customers cus
where cus.postcode like :x
or
cus.postcode like :y;

(just to show it is not sys_context to get excited about first...)

You see -- with the binds, the optimizer says, you know, it could be:

where cus.postcode like '%'

you know, that would get quite a few rows.....


tell me -- what is the distribution of the postcode. how do you analyze the table. and what does that other query do.

Also, what is the frequency by which you run this query with different values?

More feedback

Paul, March 11, 2003 - 10:08 am UTC

Right again, Tom!

Using binds from SQL*Plus instead of the sys_context code, got the same plan!

1) Distribution of postcodes is like this:
SQL> select count(*),count(postcode),count(distinct postcode) from customers;

 COUNT(*) COUNT(POSTCODE) COUNT(DISTINCTPOSTCODE)
--------- --------------- -----------------------
  5592187         3981897                  852500

There are only 9 postcodes (excluding NULL) that occur more than 100 times.  The most common postcode has 1855 occurrences.

2) Analyze done this way:
execute DBMS_STATS.GATHER_SCHEMA_STATS('${ORACLE_USER}',25,FALSE,'FOR ALL INDEXED COLUMNS',NULL,'DEFAULT',TRUE);


3) The other query (i.e. using just 1 sys_context clause) is like this:
SQL>  select cus_number from customers cus
  2  where cus.postcode like UPPER(sys_context('mycontext','postcode1'))||'%';

CUS_NUMBER  
------------- 
3860002229221 
3860002229878 
0273000769335 
0273002239570 
0273000769334 
3860001833844 
3860005094542 
3860005094543 
3860005094544 

9 rows selected.

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=22760 Card=279610 Bytes=5312590)
   1    0   TABLE ACCESS (BY INDEX ROWID) OF 'CUSTOMERS' (Cost=22760 Card=279610 Bytes=5312590)
   2    1     INDEX (RANGE SCAN) OF 'CUS_PC_I' (NON-UNIQUE) (Cost=138 Card=279610)

Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
         13  consistent gets
          0  physical reads
          0  redo size
        374  bytes sent via SQL*Net to client
        275  bytes received via SQL*Net from client
          5  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
          9  rows processed

4) This query is part of a more complex query for searching the customers table by anything the user wants - surname, date of birth, town, postcode etc.  It had been working "acceptably" until they requested being able to search on multiple postcodes (which they provide in a comma-separated string and I cut up to build up the Dynamic SQL).  I would guess it's used hundreds of times a day.


 

Tom Kyte
March 11, 2003 - 10:29 am UTC

what happens if you build a union all query instead?


select *
from customers cus
where cus.postcode like UPPER(sys_context('mycontext','postcode1'))||'%'
UNION ALL
select *
from customers cus
where cus.postcode like UPPER(sys_context('mycontext','postcode2'))||'%';



That works fine

Paul, March 11, 2003 - 12:45 pm UTC

The only problem is that my actual query can be way, way more complicated than this. If the users enter lots of different criteria the SQL generated gets large with several WHERE EXISTS clauses (which are causing me other performance problems!)

If the user enters 5 postcodes, then the amount of SQL will be generated fivefold.

Is it just the the optimizer isn't clever enough? ;-) It seems odd that running 2 queries is quicker than 1!

Tom Kyte
March 11, 2003 - 1:00 pm UTC

what is your optimizer_index_cost_adj/index_caching set to.

More feedback

Paul, March 12, 2003 - 4:39 am UTC

SQL> select * from v$parameter
  2  where name like 'optimizer_ind%';

      NUM NAME                                TYPE VALUE        
--------- ------------------------------ --------- -----------
      392 optimizer_index_cost_adj               3 100          
      393 optimizer_index_caching                3 0            
 

Tom Kyte
March 12, 2003 - 7:54 am UTC

so, in your session, see what

alter session set optimizer_index_cost_adj = 25;
alter session set optimizer_index_caching = 80;

does for you -- in SQLPLUS using binds -- just test it out.

Interesting - Different plan, but still poor performance

Paul, March 12, 2003 - 8:14 am UTC

SQL> alter session set optimizer_index_cost_adj = 25;

Session altered.

SQL> alter session set optimizer_index_caching = 80;

Session altered.

SQL>
SQL> variable x varchar2(20);
SQL> exec :x := 'NT6 7EF%';

PL/SQL procedure successfully completed.

SQL> variable y varchar2(20);
SQL> exec :y := 'NT6 8AP%';

PL/SQL procedure successfully completed.

SQL>
SQL> select cus_number from customers cus
  2   where cus.postcode like :x
  3   or cus.postcode like :y;

CUS_NUMBER  
------------- 
3860001833844 
3860005094542 
3860005094543 
3860005094544 
3860002229221 
3860002229878 
3860002386195 
3860002386196 
3860002436754 
3860002436844 
0273000769335 
0273000638189 
0273000952026 
0273002199257 
0273002239570 
0273002446665 
0273000769334 

17 rows selected.


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=6008 Card=222592 Bytes=4229248)
   1    0   CONCATENATION
   2    1     TABLE ACCESS (BY INDEX ROWID) OF 'CUSTOMERS' (Cost=318 Card=10600 Bytes=201400)
   3    2       INDEX (RANGE SCAN) OF 'CUS_PC_I' (NON-UNIQUE) (Cost=138 Card=10600)
   4    1     TABLE ACCESS (BY INDEX ROWID) OF 'CUSTOMERS' (Cost=318 Card=10600 Bytes=201400)
   5    4       INDEX (RANGE SCAN) OF 'CUS_PC_I' (NON-UNIQUE) (Cost=138 Card=10600)


Statistics
----------------------------------------------------------
          0  recursive calls
         12  db block gets
     190893  consistent gets
     190874  physical reads
          0  redo size
        583  bytes sent via SQL*Net to client
        305  bytes received via SQL*Net from client
          7  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
         17  rows processed
 

Tom Kyte
March 12, 2003 - 8:27 am UTC

but that is the same plan -- I think autotrace is lying, use tkprof and see what that says...

SQL> select cus_number from customers cus
  2  where cus.postcode like 'NT6 7EF%'
  3  or
  4  cus.postcode like 'NT6 8AP%';

CUS_NUMBER  
------------- 
3860001833844 
3860005094542 
3860005094543 
3860005094544 
3860002229221 
3860002229878 
3860002386195 
3860002386196 
3860002436754 
3860002436844 
0273000769335 
0273000638189 
0273000952026 
0273002199257 
0273002239570 
0273002446665 
0273000769334 

17 rows selected.


Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=16 Card=16 Bytes=2064)
   1    0   CONCATENATION
   2    1     TABLE ACCESS (BY INDEX ROWID) OF 'CUSTOMERS' (Cost=4 Card=1 
Bytes=129)
   3    2       INDEX (RANGE SCAN) OF 'CUS_PC_I' (NON-UNIQUE) (Cost=3 Card=1)
   4    1     TABLE ACCESS (BY INDEX ROWID) OF 'CUSTOMERS' (Cost=4 Card=1 
Bytes=129)
   5    4       INDEX (RANGE SCAN) OF 'CUS_PC_I' (NON-UNIQUE) (Cost=3 Card=1)

Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
         25  consistent gets
          0  physical reads
          0  redo size
       4239  bytes sent via SQL*Net to client
        529  bytes received via SQL*Net from client
          8  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
         17  rows processed 

Whilst I'm waiting ...

Paul, March 13, 2003 - 9:45 am UTC

... for my DBA to give me the ability to set sql_trace=true and give me access to the user_dump_dest directory, can you explain what you mean by "I think autotrace is lying"?

Does this happen very often, and more to the point, why?

Tom Kyte
March 14, 2003 - 5:13 pm UTC

it doesn't happen often -- it is because autotrace uses explain plan and that is close, not not always 101%.

I think you'll find, based on the numbes, it was a full scan.

Problem appears to have gone away!!

Paul, March 19, 2003 - 9:30 am UTC

Tom,

This is very odd.  I have only just got back from a few days away.  I ran the identical query as above, before and after setting the optimizer_index parameters.  Before - as slow as ever.  After, and all of a sudden it's working like lightning!  I've included the autotrace output below (I've got the TKPROF output too, but I don't suppose there's much point now that it's "working").  I suppose I should be happy that it's working nicely now, but I wish I knew why, and I'm a bit uneasy in case it happens again in production.

SQL> alter session set optimizer_index_cost_adj = 25;

Session altered.

SQL> alter session set optimizer_index_caching = 80;

Session altered.

SQL>
SQL> variable x varchar2(20);
SQL> exec :x := 'NT6 7EF%';

PL/SQL procedure successfully completed.

SQL> variable y varchar2(20);
SQL> exec :y := 'NT6 8AP%';

PL/SQL procedure successfully completed.

SQL>
SQL> select cus_number from customers cus
  2   where cus.postcode like :x
  3   or cus.postcode like :y;

CUS_NUMBER  
------------- 
3860001833844 
3860005094542 
3860005094543 
3860005094544 
3860002229221 
3860002229878 
3860002386195 
3860002386196 
3860002436754 
3860002436844 
0273000769335 
0273000638189 
0273000952026 
0273002199257 
0273002239570 
0273002446665 
0273000769334 

17 rows selected.

Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=6008 Card=222592 Bytes=4229248)
   1    0   CONCATENATION
   2    1     TABLE ACCESS (BY INDEX ROWID) OF 'CUSTOMERS' (Cost=318 Card=10600 Bytes=201400)
   3    2       INDEX (RANGE SCAN) OF 'CUS_PC_I' (NON-UNIQUE) (Cost=138 Card=10600)
   4    1     TABLE ACCESS (BY INDEX ROWID) OF 'CUSTOMERS' (Cost=318 Card=10600 Bytes=201400)
   5    4       INDEX (RANGE SCAN) OF 'CUS_PC_I' (NON-UNIQUE) (Cost=138 Card=10600)

Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
         25  consistent gets
          0  physical reads
          0  redo size
        544  bytes sent via SQL*Net to client
        309  bytes received via SQL*Net from client
          7  SQL*Net roundtrips to/from client
          0  sorts (memory)
          0  sorts (disk)
         17  rows processed



 

Tom Kyte
March 19, 2003 - 10:49 am UTC

the only thing I can think of is a cached cursor -- autotrace explained the query (getting the index plan) but plus ran a cached cursor -- that was associated with a full scan.

character limit on dbms_session.set_context is 256?

Sachin, April 23, 2003 - 4:36 pm UTC

Database: 8.1.7.4

Tom,
I have a varchar2(2000) column in a table...that I am trying to update through a procedure that uses dbms_session.set_context.

The procedure has a statement like:

.........
ELSIF (pOPTION = 8) THEN
dbms_session.set_context( 'CTX_CB_STRTG_SURVEY_PKG', 'C_OUTDOOR', pOUTDOOR);
vSET := vSET || ' OUTDOOR = sys_context(''CTX_CB_STRTG_SURVEY_PKG'', ''C_OUTDOOR''),';

END IF;

vSET := RTRIM (vSET,',');

--dbms_output.put_line (vSET);

vWHERE := ' USERID = :XUSERID ';

vSQL := 'UPDATE ' || vUPDATE || CHR(10) ||
' SET ' || vSET || CHR(10) ||
' WHERE ' || NVL (vWHERE, '1=1');

--write_a_string (vSQL);

EXECUTE IMMEDIATE VSQL USING pUSERID;
......
.................

I am not being able to update OUTDOOR column to anything
more than 256 characters.
I can do it through an update statement outside the procedure...but not through procedure...
So, does dbms_session.set_context has a limit on characters..
pOUTDOOR parameter does pass with the correct length...
If dbms_session.set_context does have a limit...how else would we bind parameter in this case

Thanks.

Tom Kyte
April 23, 2003 - 8:15 pm UTC

sys_context is 255

you need to use a bind variable here. DBMS_SQL will be more appropriate as you can do it procedurally.

dbms_session.set_context limit...

Sachin, April 23, 2003 - 5:29 pm UTC

Ok...I saw it in the docs...
So, is there another way to bind variables varchar2(something more than 256):

Syntax
DBMS_SESSION.SET_CONTEXT (
namespace VARCHAR2,
attribute VARCHAR2,
value VARCHAR2);

Parameters
Table 46-12 SET_CONTEXT Procedure Parameters
Parameter Description
namespace

Name of the namespace to use for the application context (limited to 30 bytes).

attribute

Name of the attribute to be set (limited to 30 bytes).

value

Value to be set (limited to 256 bytes).



Tom Kyte
April 23, 2003 - 8:15 pm UTC

dbms_sql

SET_CONTEXT.VALUE LIMIT

Sachin, April 24, 2003 - 4:26 pm UTC

DBMS_SQL or go to 9i :)
SET_CONTEXT Procedure
This procedure sets or resets the value of a context attribute.

Syntax
DBMS_SESSION.SET_CONTEXT (
namespace VARCHAR2,
attribute VARCHAR2,
value VARCHAR2,
username VARCHAR2,
client_id VARCHAR2);

Parameters
Table 65-18 SET_CONTEXT Procedure Parameters
Parameter Description
namespace
Name of the namespace to use for the application context (limited to 30 bytes).

attribute
Name of the attribute to be set (limited to 30 bytes).

value
Value to be set (limited to 4 kilobytes).

username
The username attribute of the application context

client_id
The application-specific identifier of the current database session.




cursor with like operator

mo, May 08, 2003 - 4:51 pm UTC

Tom:

I have the following implicit cursor

FOR x in (SELECT stock_number,description from stock
where description like '%p_keyword%')
LOOP

I am not getting any result? i_keyword is the word or sentence that a user passes from a web page to serach for records matching his criteria.

2. If I want to make it case insensitive can I use upper function between the % .

Thank you,

Tom Kyte
May 09, 2003 - 1:03 pm UTC

do you have anything with the string p_keyword in it?


think you might mean to code:

for x in ( sel.... where description like '%' || p_keyword || '%' )
loop


but you probably really really want to look at intermedia text (simply TEXT in 9i) and use that instead. what you have now is and will be a full scan which will not scale very well over time.

you want to be able to query

select .... where contains( description, p_keyword ) > 0


and use an index.

keyword

mo, May 09, 2003 - 6:50 pm UTC

TOm:

1. you mean this is done using intermedia.
<select .... where contains( description, p_keyword ) > 0>

DO i only ask the DBA to install internedia and use it?

2. Table is a lookup with 900 descriptions. Each description is about 30 characters. Would you still be using intermedia?

3. You were right about piping the parameter. However let us say the p_keyword is "Key" . Woold not that find all phrases that have KeyWest in them too. DO i change it to the take the p_keyword and look for a space after it in order to do an exact search"?

Thank you



Tom Kyte
May 09, 2003 - 7:14 pm UTC

1) yes. it should be installed by default, although they can choose to not install it, do you have a schema ctxsys in all-users?

2) to avoid a full scan, sure.

3) you would use intermedia, it does words.


lets say you have this data:

key to power -- is knowledge
Having knowledge is key


if you used the "space" trick you might find the first, but not the last.

DBMS_SESSION.SET_CONTEXT and ORA-01031

darren, May 12, 2003 - 1:43 pm UTC

Good quick fix, easy to locate and implement.

I'd created a new package containing DBMS_SESSION.SET_CONTEXT calls and was getting ora-01031 errors.

simply executed:

SQL> create or replace context SEARCHNEW_CONTEXT USING SPSEARCHNEW;

and fixed!
(though the java side did let me down again
but hey! thats life! (and thats java!) 

Optimizer Settings Earlier in Post

Matt, May 14, 2003 - 1:21 am UTC

Earlier you suggested changed some optimizer parameters. I understand thst this affect the weightings that the CBO applies to accessing tables via an index or via a full scan. I am just curious why you chose these particular values. Obviously you have seen these settings work well in the past, but was there any other criteria that caused you to choose these particular values?

alter session set optimizer_index_cost_adj = 25;
alter session set optimizer_index_caching = 80;

I am working on converting queries from the RBO to the CBO and have been going through a tuning exercise to alter these values. However, I have taken the approach of only altering the optimizer_index_cost_adj parameter. I am seeing improvements in CBO timings as I move optimizer_index_cost_adj from 100 down to 70 compared to the RBO but nothing significant. I am definately not seeing any benefits over the CBO so far (I know that these will come when I find the right magic values).

Surely,

alter session set optimizer_index_cost_adj = 25;
alter session set optimizer_index_caching = 80;

is not a rule of thumb? ( :o) )

Best Regards.

Tom Kyte
May 14, 2003 - 7:00 am UTC

they are two sides of the pendulum.

You want to see a big swing? swing hard to the other side. I just started "low"

Confirmation.

Matt, May 14, 2003 - 8:02 pm UTC

I see.

So you are saying that:

optimizer_index_cost_adj = 25;
optimizer_index_caching = 80;

is a slight push to the optimizer to alter it's behaviour. A bigger push would then be:

optimizer_index_cost_adj = 75;
optimizer_index_caching = 20;

Is it always necessary to alter these parameters as a pair?

If so, is it as simple as geometrically defining a straight line between these two points above to find the sweet spot?

Matt

Tom Kyte
May 14, 2003 - 11:50 pm UTC

no, it takes it HARD to port, not soft.

the defaults:

optimizer_index_caching integer 0
optimizer_index_cost_adj integer 100


the other end of the spectrum:
Hard Really Hard
to port to port
optimizer_index_caching integer 80 90
optimizer_index_cost_adj integer 25 10


cost_adj -> zero implies indexes are cheap, really cheap
index_caching -> 100 implies indexes incurr no PIO

coun of cursor

mo, May 19, 2003 - 6:03 pm UTC

Tom:

I remember you had an excellent article on explaining how to count records inside/outside a cursor but I tried all kind of searches to find it and I can not. Can you point me to it?

Thank you

Tom Kyte
May 20, 2003 - 7:26 am UTC

you must have been dreaming? I don't know what you are refering to.

the only way to know the number of records in a "cursor" is to actually fetch them all -- at which point the cursor is no longer a cursor, it is empty.


of course, you could add "count(*) over()" as a column but boy would that be a huge mistake and kill your performance totally.

cursor

mo, May 19, 2003 - 6:20 pm UTC

Tom:

if i have

for x in ( select * from table)
LOOP
---HERE can i get how many records were retrieved
...
....

END LOOP;

Thank you,


Tom Kyte
May 20, 2003 - 7:29 am UTC

add rownum to the query or count them.

Great Information

Deanna, May 23, 2003 - 6:52 am UTC

This listing was very helpful in understanding how to use bind variable. It is one of the most valuable pieces of information out on the site! Thank you


Do you know how to use this with Intermedia. When applying the code I get "Invalid Relational Operator"
I tried modifying the quotes but had no luck

Thanks

PROCEDURE REPORT_SEARCH (p_kw1 IN VARCHAR2 DEFAULT NULL)

AS
TYPE RC IS REF CURSOR;
v_query VARCHAR2(3000);
l_cursor RC;
l_query VARCHAR2(3000)
DEFAULT ('SELECT a.url

FROM test_table a
WHERE 1=1');

cursor l_template IS
SELECT a.url
FROM test_table a;

l_rec l_template%ROWTYPE;

BEGIN
IF ( p_kw1 IS NOT NULL ) THEN
dbms_session.set_context( 'test_ctx', 'KW1',
'contains( url, p_kw1 ) > 0 ' );

l_query := l_query ||
' and sys_context( ''test_ctx'', ''KW1'' ) ';
END IF;
OPEN l_cursor for l_query;
LOOP
FETCH l_cursor into l_rec;
EXIT WHEN l_cursor%NOTFOUND;

dbms_output.put_line( l_rec.url );
END LOOP;

CLOSE l_cursor;
END;

Deanna, May 23, 2003 - 5:56 pm UTC

Hi Tom

Thanks for the reply
I read the information in the following link, and I still get "Invalid relational Operator" at run time

I matched this syntax:
if ( p_ename is NOT NULL ) then
l_query := l_query ||
' and contains( field, :p_ename ) > 0 '
with this syntax

IF ( p_kw1 IS NOT NULL ) THEN
dbms_session.set_context( 'report_search_ctx', 'KW1',
'contains( url, :p_kw1 ) > 0' );
l_query := l_query ||
'and sys_context( ''report_search_ctx'', ''KW1'' ) ';
END IF;

Is the problem with the sys_contex ?


Tom Kyte
May 24, 2003 - 10:12 am UTC

look at the query you would be generating. you are basically saying:


select * from t where f(x,y);


f being a function. that does not make sense.

you do not put the PREDICATE into sys_context, you put values to be passed to a predicate in there.

You cannot do this:


set_context( ...., ' empno = 1234 ' )

and expect "select * from emp where sys_context( ... )" to work -- same with contains

A reader, May 25, 2003 - 7:37 am UTC

tom, just to get it 100% right: the SYS_CONTEXT issue does NOT apply to code like that?

open ref_cursor for
select <some columns> from <some tables>
where <some joins>
and col1 = p_MyParam;

(but only to GENERATED SQL statements?)

Tom Kyte
May 25, 2003 - 10:01 am UTC

it applies to ANY sql statement, sys_context is just a function that returns a string -- use it anywhere you would put a string (character string literal)

Deanna, May 25, 2003 - 7:48 am UTC

Hi Tom

Thanks again for the information... especially on a 3 day weekend :)

I tried this

IF ( p_kw1 IS NOT NULL ) THEN
dbms_session.set_context( 'report_search_ctx', 'KW1',p_kw1 );

l_query := l_query ||
' and contains (url, (sys_contex(''report_search_ctx'', ''KW1'' ))) >0 ' ;

Thinking that (sys_contex(''report_search_ctx'', ''KW1'' )) contained my value therefore if I placed it as the value in the contains clause that would work.

Instead I get now Invalid column name

How would you resolve this problem? Ill be working on it further to try to "get the clues" in the last response

Tom Kyte
May 25, 2003 - 10:02 am UTC

just read:

</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:5225986313862#5261789008763 <code>

it shows exactly what you need to do.

A reader, May 25, 2003 - 11:22 am UTC

sorry for that, tom, but to me it 's still not 102% clear if one should use SYS_CONTEXT rather than "normal" parameters (such as 'p_MyParam' in my sample above):

is there any (major) difference between:

open ref_cursor for
select <some columns> from <some tables>
where <some joins>
and col1 = p_MyParam;

and:

open ref_cursor for
select <some columns> from <some tables>
where <some joins>
and col1 = SYS_CONTEXT('MyCtx', 'p_MyParam');

I've never thought of using SYS_CONTEXT that way but just only parameters: their values get BOUND to the query - not their values "copied" into it, right?

so, can one summarize: use SYS_CONTEXT wherever string literals occur AND CHANGE between several executions of the statement (otherwise there 's no advantage too).

Tom Kyte
May 25, 2003 - 11:39 am UTC

I would use


open ref_cursor for
select <some columns> from <some tables>
where <some joins>
and col1 = p_MyParam;



rather then

open ref_cursor for
select <some columns> from <some tables>
where <some joins>
and col1 = SYS_CONTEXT('MyCtx', 'p_MyParam');

because it takes less code to do so. sys_context() works just like a bind.

cursor

mo, May 25, 2003 - 9:42 pm UTC

Tom:

when you do:

l_query varchars(2000) default 'select * from table where user_id = p_user_id'

open l_cursor from l_query;

I got an error. it does not seem to recognize that p_user_id is a parameter and substitute the value. I also tried this:

l_query varchars(2000) default 'select * from table where user_id ='||p_user_id;

and it did not work. are you stuck with sys_context here?




Tom Kyte
May 26, 2003 - 9:19 am UTC

no, you are stuck reading the documentation ;)


l_query := 'select * from table where user_id = :p_user_id';
open l_cursor from l_query USING p_user_id;




U tell me dude

A reader, May 26, 2003 - 12:15 am UTC

your code :
l_query varchars(2000) default 'select * from table where user_id = p_user_id'

open l_cursor from l_query;
correct :
l_query varchars(2000) default 'select * from table where user_id = :p_user_id'

open l_cursor for l_query using p_user_id;


dbms_session.set_context in a loop

Sachin, May 27, 2003 - 5:49 pm UTC

(Version 8.1.7.4.0)

Tom,

I have a procedure "A" that builds a string and returns to procedure "B"
that calls it.

--CREATING cONTEXT
CREATE OR REPLACE CONTEXT CTX_WHERE USING A;

--CREATING PROCEDURE "A"
CREATE OR REPLACE PROCEDURE A (pCOL_ARRAY TYPES_PKG.ARRAY DEFAULT TYPES_PKG.ARRAY(),
pRELATION_ARRAY TYPES_PKG.ARRAY DEFAULT TYPES_PKG.ARRAY(),
pVALUE_ARRAY TYPES_PKG.ARRAY DEFAULT TYPES_PKG.ARRAY(),
pQUERY OUT LONG) AS

V_SEP VARCHAR2(4000) := ' AND ';
vQUERY LONG := NULL;

v_REC_COL VARCHAR2(4000);
v_REC_RELATION VARCHAR2(4000);
v_REC_VALUE VARCHAR2(4000);

BEGIN

FOR I IN 1 .. pCOL_ARRAY.COUNT LOOP


v_REC_COL := pCOL_ARRAY(I);

v_REC_RELATION := pRELATION_ARRAY(I);


dbms_session.set_context( 'CTX_WHERE', 'CTX_CATCH_ALL', pVALUE_ARRAY(I));
v_REC_VALUE := 'Sys_context( ''CTX_WHERE'', ''CTX_CATCH_ALL'' )';
--v_REC_VALUE := pVALUE_ARRAY(I);


IF vQUERY IS NULL THEN
vQUERY := v_REC_COL || ' ' || v_REC_RELATION || ' ' || v_REC_VALUE;

ELSE
vQUERY := vQUERY || V_SEP || v_REC_COL || ' ' || v_REC_RELATION || ' ' || v_REC_VALUE;

END IF;


END LOOP;

pQUERY := vQUERY;

END A;



So, For Example...if we pass procedure A values as follows:
pCOL_ARRAY as TOOLS_PKG.MAKE_AN_ARRAY('EMPNO','DEPTNO')
pRELATION_ARRAY AS TOOLS_PKG.MAKE_AN_ARRAY('=','=')
pVALUE_ARRAY AS TOOLS_PKG.'2812','10')

We should get...
EMPNO = 2812 AND DEPTNO = 10

and we do get that...if we don't use contexts...i.e. uncommenting
the statement "v_REC_VALUE := pVALUE_ARRAY(I)"...and commenting out "dbms_session.set_context..."
but when do use contexts...I do net get the desired results..I can not see the values
stored in context..but my query does not return any results.

What am I doing wrong here?
Should the context be created using procedure B..since the procedure B calls procedure A, Could
that be the mistake?

Tom Kyte
May 27, 2003 - 6:00 pm UTC

hows about this -- a simple, concise, yet complete example that demonstrates the issue in a manner I too can reproduce on my system?

eg: a test case....


but actually -- the issue seems to be one of logic here....

You have one context variable 'CTX_CATCH_ALL'

it can have but one value at a time. Your query ends up being:

.... empno = sys_context( 'ctx_where', 'ctx_catch_all' ) and deptno = sys_context( 'ctx_where', 'ctx_catch_all' ) ....


well, ctx-catch-all will just have whatever LAST value you stuffed in it -- doubtful you have an empno = deptno and deptno = sys_context() -- but that is what you coded in effect....

maybe

FOR I IN 1 .. pCOL_ARRAY.COUNT LOOP

dbms_session.set_context
( 'CTX_WHERE', 'bv_'||i, pVALUE_ARRAY(I));

IF vQUERY IS NULL THEN
vQUERY := pCol_array(i) || ' ' || pRelation_array(i) ||
' sys_context( ''ctx_where'', ''bv_' || i || ''' );
ELSE
vQUERY := vQUERY || V_SEP || pCol_array(i) || ' ' ||
pRelation_array(i) ||
' sys_context( ''ctx_where'', ''bv_' || i || ''' );
END IF;
END LOOP;


Multiple Contexts or single

Sachin, May 27, 2003 - 6:38 pm UTC

Thanks Tom,
Another Question...
In the Procedure A, I also evaluate the value of v_REC_RELATION (i.e. pRELATION_ARRAY(I))....as follows
IF (v_REC_RELATION = 'BEGINS_WITH') THEN

v_REC_RELATION := ' LIKE ';
dbms_session.set_context( 'CTX_WHERE', 'CTX_BEGIN', pVALUE_ARRAY(I) || '%');
v_REC_VALUE := 'Sys_context( ''CTX_WHERE'', ''CTX_BEGIN'' )';

ELSIF (v_REC_RELATION = 'ENDS_WITH') THEN

v_REC_RELATION := ' LIKE ';
dbms_session.set_context( 'CTX_WHERE', 'CTX_END', '%' || pVALUE_ARRAY(I));
v_REC_VALUE := 'Sys_context( ''CTX_WHERE'', ''CTX_END'' )';

ELSIF (v_REC_RELATION = 'PHRASE') THEN

v_REC_RELATION := ' LIKE ';
dbms_session.set_context( 'CTX_WHERE', 'CTX_PHRASE', '%' || pVALUE_ARRAY(I) || '%');
v_REC_VALUE := 'Sys_context( ''CTX_WHERE'', ''CTX_PHRASE'' )';

ELSIF (v_REC_RELATION = 'SOUNDS_LIKE') THEN


v_REC_COL := 'SOUNDEX(' || pCOL_ARRAY(I) || ')';

v_REC_RELATION := '=';
dbms_session.set_context( 'CTX_WHERE', 'CTX_SOUND', 'SOUNDEX(' || pVALUE_ARRAY(I) || ')');
v_REC_VALUE := 'Sys_context( ''CTX_WHERE'', ''CTX_SOUND'' )';

end if;


Question:
Is it better to set context just once:
as
" dbms_session.set_context( 'CTX_WHERE', 'BV_' || I, pVALUE_ARRAY(I));"

then keep changing the value for v_REC_VALUE (inside an if condition) as
v_REC_VALUE := '%' || 'Sys_context( ''CTX_WHERE'', ''BV_' || I || ''' )';

v_REC_VALUE := 'Sys_context( ''CTX_WHERE'', ''BV_' || I || ''' )' || '%';

....
....








Tom Kyte
May 27, 2003 - 6:43 pm UTC

up to you -- whatever makes more sense codewise to you

Cursor in 8.1.7

Randy, May 31, 2003 - 7:45 pm UTC

Hi Tom,
I have a cursor for loop which runs on a varchar2(4000) column. In 9i the cursor runs no problem. However, in 8.1.7, the column returns a blank value with > 1,000 characters. I thought maybe this was the 32K PL/SQL limit, but then why does this work in 9i? I have been looking for days for the answer on this one. Any help you can provide will be greatly appreciated!

Tom Kyte
May 31, 2003 - 9:23 pm UTC

you will have to provide a test case.

I've never observed what you say -- never.

Randy, May 31, 2003 - 9:49 pm UTC

Thanks for your respose...
I have the following PL/SQL statement which outputs data to MS word using Oracle COM automation feature...

declare

i binary_integer;

filename varchar2(100);




begin

filename:= 'c:\test\report_'||sysdate;

i:=ORDWord.CreateWordObject('');

i:=ORDWord.FileNew();
i:=ORDWord.FormatFilePageSetup(1, 1, 54, 54, 54, 54, 0, 15840, 11520);
i:=ORDWord.FormatFontSize(12, 1, 1, 0, 0, 0, 0, 0, 0, 0, 0, 0, 1, 0, 0, 2, 1, 0);
i:=ORDWord.FormatFontParagraph(0, 0, 0, 0, 0, 0, 1);
i:=ORDWord.InsertText('*** FOR OFFICIAL USE ONLY ***');
i:=ORDWord.InsertNewLine();
i:=ORDWord.InsertText('PM Combat Systems Weekly Significant Activity Report');
i:=ORDWord.InsertNewLine();
i:=ORDWord.InsertNewLine();
i:=ORDWord.FormatFontSize(11, 0, 1, 0, 0, 0, 0, 0, 0, 0, 0, 0, 1, 0, 0, 2, 1, 0);
i:=ORDWord.InsertText('Period Ending: '||sysdate);
i:=ORDWord.InsertNewLine();
i:=ORDWord.InsertNewLine();
i:=ORDWord.InsertNewLine();
i:=ORDWord.InsertNewLine();

For c1_rec IN (SELECT ROWNUM, SUBJECT, ISSUE, RESPONSIBLE_POC, PHONE_NUMBER FROM one_liner2 where status = 'Approved')
LOOP

i:=ORDWord.FormatFontSize(10, 1, 1, 0, 0, 0, 0, 0, 0, 0, 0, 0, 1, 0, 0, 2, 1, 0);
i:=ORDWord.FormatFontParagraph(0, 0, 0, 0, 0, 0, 0);
i:=ORDWord.InsertText(c1_rec.rownum||'. '||c1_rec.SUBJECT||':');
i:=ORDWord.FormatFontSize(10, 0, 1, 0, 0, 0, 0, 0, 0, 0, 0, 0, 1, 0, 0, 2, 0, 0);
i:=ORDWord.FormatFontParagraph(0, 0, 0, 0, 0, 0, 0);
i:=ORDWord.InsertNewLine();
i:=ORDWord.InsertText(c1_rec.ISSUE);
i:=ORDWord.InsertNewLine();
i:=ORDWord.InsertNewLine();
i:=ORDWord.InsertText(c1_rec.RESPONSIBLE_POC||'/'||c1_rec.phone_number);
i:=ORDWord.InsertNewLine();
i:=ORDWord.InsertNewLine();

END LOOP;

i:=ORDWord.FileSaveAs(filename);

i:=ORDWord.FileClose();

end;

When I run the statement in 9i it works exactly the way it should. However, when I run in our current production environment any data stored in the issues varchar2(4000) column that is > 1000 characters the cursor returns nothing. Everything else returns fine.

Tom Kyte
June 01, 2003 - 9:08 am UTC

so, develop a small test case that shows where the issue is. I mean -- I'll betcha that the cursor is returning the data but the ORDWord thing is having issues with it.

eg: either keep the cursor but remove the ordword calls and just dbms_output substrs of the data. If you see data -- then you've narrowed the problem down.

Once you do that, remove the sql and just make ordword calls. You know, declare a local variable of varchar2(4000) -- fill it up and use it instead of SQL (so you have a reproducible test case that standsalone that you can give to support and they too can run).

After that -- try the logical workaround -- writing out the string in 512 byte chunks instead of in a single call. Sort of like a procedure "P" I keep around for dbms_output which only does 255 characters:

create or replace procedure p ( p_str in varchar2 )
is
l_str long := p_str;
begin
loop
exit when l_str is null;
dbms_output.put_line( substr( l_str, 1, 250 ) );
l_str := substr( l_str, 251 );
end loop;
end;
/

and see if that doesn't work around your issue.



It is funny, if you go back to your text above:

...
I have a cursor for loop which runs on a varchar2(4000) column. In 9i the
cursor runs no problem. However, in 8.1.7, the column returns a blank value
with > 1,000 characters. I thought maybe this was the 32K PL/SQL limit, but
then why does this work in 9i? I have been looking for days for the answer on
this one. Any help you can provide will be greatly appreciated!
......

you make no mention of ORDWord. You never tested the "cursor" (it undoubtably is NOT the issue here -- not a chance, it is not part of the problem at all).


You really need a TEST system that mirrors PRODUCTION -- developing in 9i and deploying to 8i just is a recipe for disaster -- cannot be done. You need a system whereby you can isolate these issues (production isn't that environment). I certainly hope you have such a system -- you might have to run 5 or 6 variants of the above code to isolate the exact issue and then you need to develop a workaround for it (i won't be able to -- you see, my computers don't do "com" -- open systems, sure, not com. My solution would be UTL_FILE, write some HTML. Pretty much every editor reads HTML. "open", "easy", "portable" -- that is what it is all about)

Randy, June 01, 2003 - 9:59 am UTC

Hi Tom,
Thanks for the response on Sunday:-). I figured this was a cursor problem related to 8.1.7 because it works in 9. But from what you're telling me this isn't the case. I will try some of your suggestions and see where it gets me. Again, thanks for taking the time to read my question!


Randy, June 02, 2003 - 12:11 pm UTC

Hi Tom,
You were right, it was the ORDWord causing the problem. I tried your suggestions and I think I figured out a possible work around. If I pull the data using the ORDWord.inserttext function 1000 characters at a time it works fine. However, if the data is < 1000 characters I get a fetched column value is NULL for substr > 1000 characters? Can I write an exception clause if ORDWord.Inserttext(v_issue2) –- v_issue2 is the variable that holds > 1000 characters-- is null then do nothing?


Thanks,
Randy

Tom Kyte
June 02, 2003 - 12:36 pm UTC

just use a function like this:

create or replace procedure p ( p_str in varchar2 )
is
l_str long := p_str;
begin
loop
exit when l_str is null;
dbms_output.put_line( substr( l_str, 1, 250 ) );
l_str := substr( l_str, 251 );
end loop;
end;
/

using ordword instead of dbms_output -- that should not through any exceptions

Randy, June 02, 2003 - 1:39 pm UTC

Tom,
Thanks for all your help. Your example was exactly what I was looking for!!

Randy




Something Global inside triggers

Sachin, June 05, 2003 - 11:42 am UTC

8.1.7.4.0
Tom,
We have some Auditing triggers on our tables..
USER is accessible to triggers automatically..
I don't know any way to pass parameters to triggers.
is there a way to have a variable that we can put in some kind of global context..that will be accessible to the triggers...for a session.

Thanks.

Tom Kyte
June 05, 2003 - 1:30 pm UTC

set a package variable.

create or replace package my_pkg
as
some_variable varchar2(25);
end;

anything can access my_pkg.some_variable now.

context for triggers

Sachin, June 05, 2003 - 4:58 pm UTC

Database Version: 8.1.7.4.0
Sorry for not being clear...
Actually, I am trying to catch the persons identity who is logged in (to use it for MODIFIEDBY column).
Database user who is logged into the app is always the same..so does not help us for auditing.
When a user logs in the app catches their NT login name...
but it is not a USER parameter (Select user from dual) that is visible to the trigger..so I was wondering if their is a way to catch that for a session..and use it in a trigger..
instead of moving some of the auditing to procedures...
Front end is Active Server Pages


Tom Kyte
June 05, 2003 - 6:35 pm UTC

not without the application itself telling us, we cannot reach out and just grab this information.

You can use dbms_application_info.set_client_info (then userenv('client_info') will have it)

You can create an application context and set it.

You can create a package with a "set user", "get user" function and use that.

orword

mo, June 06, 2003 - 5:00 pm UTC

Tom:

what is ordword or oracle com software? can i write a pl/sql procedure that will dump my table into a MS Word file using that?



Tom Kyte
June 06, 2003 - 7:59 pm UTC

you can, but I think that would be wrong.

generate open solutions -- make it so anything can use your output.

HTML -- open
XML -- open
COM -- not open (or any of its other names like dcom, activex, .nyet, whatever)



COM

mo, June 07, 2003 - 1:59 pm UTC

Tom:

Thanks, but is COM software part of oracle database? or it is some extra tool that you have to get?

Tom Kyte
June 07, 2003 - 2:30 pm UTC

COM would be a MS protocol.

On Windows, the Oracle server comes with a package that lets you make COM callouts to COM enabled things.

On Unix and other platforms, it doesn't since that protocol is pretty much all about -- well -- windows.

SYS_CONTEXT

Sachin, June 12, 2003 - 11:11 am UTC

8.1.7.4.0
Tom,

What is the difference between these two:
SELECT USERENV( 'client_info' ) INTO VUSER from dual;
SELECT SYS_CONTEXT('USERENV','CLIENT_INFO') from dual;

Thanks.



Tom Kyte
June 12, 2003 - 11:21 am UTC

SELECT SYS_CONTEXT('USERENV','CLIENT_INFO') from dual;
is the new prefered way where as

SELECT USERENV( 'client_info' ) INTO VUSER from dual;
is the old, deprecated way.

since sys_context was added and lots of new functionality surrounding it is avaiable, it is prefered that you use sys_context but userenv() will remain for quite a while as there is lots of code out there that uses it (including the oracle data dictionary views themselves)

GREAT!!!

lou, June 12, 2003 - 11:47 am UTC

The information was great!!! however, how can I put an
index to speed things up in this kind of situation. I am very
interested on how you andwer this because you are using LIKE thus preventing it from using an index.


Thanks,

LNL

Tom Kyte
June 12, 2003 - 1:04 pm UTC

like doesn't prevent an index?

not sure what you are asking for here?

related to original question

sam, June 17, 2003 - 11:48 am UTC

Hi tom

I am not sure if I posted this question earlier. I don't see it after 1 hour.

can we have dynamic cursors with 'for update / current of '
clauses ??

TYPE reference_cur IS REF CURSOR;
c1 reference_cur;

open c1 for 'select cust_num from ' || table_name || ' for update'; -- table_name is procedure input parameter
loop
fetch c1 into custnum;
exit when c1%notfound;
-- some calculations here
execute immediate 'update ' || table_name || ' set
deleted_ind=' || '''N''' || ' where current of c1';

end loop;

thanks





Tom Kyte
June 17, 2003 - 12:54 pm UTC

look on the other page where you put this

</code> http://docs.oracle.com/docs/cd/B10501_01/server.920/a96521/tspaces.htm#19171 <code>



I did not put this earlier

sam, June 17, 2003 - 1:34 pm UTC

Tom

I searched but this is the only thread I have put my question in.

Also The link you provided as a answer is for tablespace link.

Please answer my question

Tom Kyte
June 17, 2003 - 4:34 pm UTC

sorry but you did,

I pasted the wrong link, see

</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:584023239495#10489907277766 <code>

which is the other page you asked this on.


Can this be bounded

Sachin, June 25, 2003 - 3:56 pm UTC

8.1.7.4

Tom,
I wrote a procedure to build the where clause..
For example

procedure build_where (pCOL ARRAY,
pRELATION ARRAY,
pVALUE ARRAY,
pQUERY OUT LONG);

Then I should be able to pass array params to it like
pCOL := 'emplid','empname','dept'
pRELATION := '=','=','is'
pVALUE := '2030','SMITH','NULL'

and it should return:
emplid = '2030' and empname = 'SMITH'
AND dept is null

I am using dbms_context to bind values for pVALUE.
It all works fine for all the cases..except for
the third value:
dept is null.

The procedure does produce the string the way it supposed to..and I check the values with in sys_context..it is 'NULL'

but when I open the dynamic query..I get this error:
ORA-00908: missing NULL keyword

Is it because it's a key word and only values can be bounded...Please help..

Thanks


Tom Kyte
June 25, 2003 - 8:44 pm UTC

you'll loop over p_col right


for i in 1 ... p_col.count
loop
l_where := l_where || ' and ' || pCol(i) || ' ' || pRelation(i);
if ( pValue(i) is null )
then
l_where := l_where || ' null';
else
dbms_session.set_context( .... );
l_where := l_where || ' sys_context( ''ctx'', .....
end if;
end loop


and set:

pValue := '2030', 'SMITH', null


(or check for the STRING null).... Additionally - you need a 4th array -- DATATYPE of S, N, D (string number date) so you know when to wrap the sys_context call by to_number and to_date!

How to use session context in mod_plsql

A reader, July 01, 2003 - 5:42 pm UTC

Tom,

If I use mod_pl/sql and session is stateless, how does the session context work? since session is changing from page to page.

Tom Kyte
July 01, 2003 - 7:50 pm UTC

well, in this example, it didn't matter that is was stateless. we used the context to "bind" with.

see
</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:5669294472933 <code>
for "global application contexts" which can persist over connections.

Maharaj

Maharaj ki Jai Ho, July 01, 2003 - 11:12 pm UTC

CREATE OR REPLACE FUNCTION test(loan NUMBER,loantype VARCHAR2)
RETURN VARCHAR2
IS
CURSOR loanc(Cloan NUMBER) IS
SELECT loan_total,loan_interest,loan_category
FROM loans
WHERE loan_KEY=cloan;

fun_return VARCHAR2(1) := 'Y';
BEGIN
IF loantype='interim' THEN
FOR REC IN loanc(loan) LOOP
IF REC.loan_total=0 OR (REC.loan_interest=0 AND loan_category <> 'I')
THEN fun_return:='N';
EXIT;
END IF;

END LOOP;
END IF;


RETURN fun_return
END;

Tom, my requirment is that , just like that above function, I will have to do 6 more functions doing the same validation
but against different loan categories , and I will have to hit their respective tables.

One straight forward way is to declare 6 cursors, and repeat the above for all the 6 scenarios i.e. for all the 6 loan categories.

But I want to know if I can write a generic routine , which can account for a single function taking care of all the 6 scenarios.

The function obvious should accept 6 different table names, one at a given time, and also different column names.

The number of columns might also differ as in two cases we will be selecting only the first two columns, in other cases there will be 3.

Can you suggest the most correct method to write this dynamic sql , which also uses bind variables.


Thanks

Maharaj

Tom Kyte
July 02, 2003 - 8:02 am UTC

You "could", but you "shouldn't"

static sql is better then dynamic sql -- more performant, easier to debug/maintain.  6 is a small number.

code should just be a single SELECT INTO, no procedural code needed or desired:

ops$tkyte@ORA920> create table loans ( loan_key int, loan_total int, loan_interest int, loan_category char(1) );

Table created.

ops$tkyte@ORA920>
ops$tkyte@ORA920> variable loan number
ops$tkyte@ORA920> exec :loan := 55;

PL/SQL procedure successfully completed.

ops$tkyte@ORA920>
ops$tkyte@ORA920> select decode( count(*), 1, 'N', 'Y' )
  2    from dual
  3   where exists ( select null
  4                    from loans
  5                   where loan_key = :loan
  6                     and ( loan_total = 0
  7                           or
  8                           (loan_interest = 0 and loan_category <> 'I')
  9                         )
 10                )
 11  /

D
-
Y

ops$tkyte@ORA920>
ops$tkyte@ORA920> insert into loans values ( 55, 0, 0, 'x' );

1 row created.

ops$tkyte@ORA920>
ops$tkyte@ORA920> select decode( count(*), 1, 'N', 'Y' )
  2    from dual
  3   where exists ( select null
  4                    from loans
  5                   where loan_key = :loan
  6                     and ( loan_total = 0
  7                           or
  8                           (loan_interest = 0 and loan_category <> 'I')
  9                         )
 10                )
 11  /

D
-
N


 

dynamic columns

ramesh, July 29, 2003 - 9:09 am UTC

Tom,

This is in response to your suggestion about using DBMS_SQL for the situation where different number of columns are to be selected at different times.

My question is when i dont know what columns i use until runtime how can i do
DBMS.define_column(....) !!!

My actual need is like this.

We have a table with coulmns for each month from 2001 year onwards.i.e like c_200001,c_200002 .. c_200306
Every month we add a new column in a table and ppopulate values into column from c_200001 to the latest added column.
I have a script to generate SQL .. but i got stuck at taking the values into variables and then use them to update the table columns.
TIA
Rd

Tom Kyte
July 29, 2003 - 11:09 am UTC

dbms_sql.describe_columns tells you how many and what types they are.

this does sound like "a bad design", seems to me you want to add a ROW per month, not a col

dynamic columns

ramesh, July 30, 2003 - 9:28 am UTC

Hi Tom,

Thanks for the followup.

You may be right .. it may be a bad design..
But what i asked was about columns not rows.

Please suggest me a better way..

I am pasting some parts of the code ..
--** code starts
....
type mthstab is table of varchar2(7) index by binary_integer;
mths mthstab;
....
....
mths(1):='jan'; mths(7):='jul';
mths(2):='feb'; mths(8):='aug';
mths(3):='mar'; mths(9):='sep';
mths(4):='apr'; mths(10):='oct';
mths(5):='may'; mths(11):='nov';
mths(6):='jun'; mths(12):='dec';

vSql:='select acct_num ';
for y in 2000 .. to_char(add_months(sysdate,-1),'yyyymm')
loop
for m in 1 .. 12
loop
vSql:=vSql||',sum(case when period='||y||lpad(m,2,'0')||'
then balance else 0 end) balance'||'_'||mths(m)||'_'||substr(y,3,2);
end loop;
end loop;
vSql:=vSql||' from accounts where acct_num=sys_context(''ACC_CTX'',''ACC'') and period between ''200001'' and '||vper||' group by acct_num';
...
...
--** code ends

The above loop creates an SQL as follows..

select acct_num
,sum(case when period=200001 then balance else 0 end) balance_jan_00
...
...
,sum(case when period=200001 then balance else 0 end) balance_jul_03
from accounts
where acct_num=sys_context('ACC_CTX','ACC')
and period between '200001' and '200306' group by acct_num;

-- My source table (accounts) has records for each month ..
-- My target table has column for each month
-- My objective is to take this growing records of source table to growing columns of target table.


Kindly suggest something.

Thanks
Rd

Tom Kyte
July 30, 2003 - 10:10 am UTC

the better way is what I did suggest -- that you fix the model.


else you are writing dynamic sql every single time. nothing I can do to make that easy, efficient, fast, sleek, or correct.

it looks like you have the data correctly stored and are being forced to pivot it.

you've done all that you can do.


dynamic columns

ramesh, July 30, 2003 - 10:31 am UTC

Hi ,

Thanks again ..
There is nothing i can do with the model.
We have gotto feed a SAS system and they need columns growing.

This loading will be monthly run .. and it would be a couple of thousand records a month to process.

If you say its worst possible approach i look for a totally different approach. Or you may suggect me how i can reacd the columns returned by Cursor in to array or whatever so that i can update the target table.

I will have to use another dymanic SQL ( in the same manner i did) for updation also for which i dont think i can do otherwise.

Thanks
Rd


Tom Kyte
July 30, 2003 - 10:56 am UTC

what you are doing -- with the pivot query -- is the approach to take to pivot data like that.

a couple thousand records won't be very hard to do.

Session contexts with shared connections

Steve, August 22, 2003 - 1:35 pm UTC

Tom
I have written a procedure to build a dynamic statement using the session context method described here which works a treat. I am just a bit concerned how this works when the connections are shared for multiple web users. Should I be concerned about conexts from a previous user persisting in a session? It is not possible to clear the contexts after execution of the procedure since the ref_cursor returned to the calling app, will then return no rows. The alternative is to clear the contexts at the start of each execution but is it worth the overhead? Any contexts used in the new query will overwrite the old anyway? Your advice will be much appreciated.

Tom Kyte
August 22, 2003 - 8:06 pm UTC

context is uga memory - migrates with the session when using shared server.

if you are using a connection pool -- you need to clear/set the context after a "grab connection" call.

Which is more faster

Mohan K, August 25, 2003 - 4:53 am UTC

I am developing an application package in PL/SQL where I have two choices. One to write static sql statements and the other to develop generic package where the tablename and the column name is passed dynamically by the calling application. My question is for a given query on a table which is faster, static SQL or Dynamic SQL.

If the query is static SQL the everything can be written in one SQL statement. If it is dynamic SQL then there will be a sequence of procedure calls in a loop. Is there any way to make the performance of both mwthods same.

Mohan


Tom Kyte
August 25, 2003 - 6:41 am UTC

static sql wins hands down for so so so many reasons.

performance being one.
maintainence another.
dependency tracking a third.
"bug free code" for a fourth.

and so on.

use dynamic sql if and only if a static sql approach is not in the realm of possible.

the only way to make a dynamic sql implementation of a routine that could be done via static sql perform as well would be to recode it using static sql :)

Hi Tom

A reader, August 25, 2003 - 10:37 pm UTC

Can you please explain?
"performance being one.
maintainence another.
dependency tracking a third.
"bug free code" for a fourth.
"

I know performance is better in static?

But I don't understand the two points
maintenance
dependency tracking

Could you explain these a little more?

Thanx!

A reader, September 04, 2003 - 11:45 am UTC


9.2.0.4 and sys_context

Arun Gupta, September 21, 2003 - 12:09 pm UTC

Tom
We are using sys_context on data from remote tables. Quoting from your example:

begin
16
17 if ( p_ename is NOT NULL ) then
18 dbms_session.set_context( 'MY_CTX', 'ENAME',
19 '%'||upper(p_ename)||'%');
20 l_query := l_query ||
21 ' and ename like
22 sys_context( ''MY_CTX'', ''ENAME'' ) ';
23 end if;

The context is set on the local database but the query refers to tables and columns on the remote database through a database link. Till 9.2.0.3, Oracle was fetching all records from remote table and filtering them on the local database as seen in the explain plan. Since the context namespace was declared on the local database, the query was giving correct results.

After applying the 9.2.0.4 patch, the optimizer started sending the entire where clause including sys_context to the remote database. Since the context namespace does not exist on the remote database, the where clause never finds any matching data and query fails to return any results.

Any suggestions?

Thanks...


Tom Kyte
September 21, 2003 - 1:03 pm UTC

use the driving site hint as a workaround, or you can try the alternative suggested above of:

...
Can't you achieve the same (without using sys_context), creating dummy WHERE
condition if passed parameter has null value. So, you will always use the same
number of bind variables in USING clause.
if ( p_ename is NOT NULL ) then
l_query := l_query ||
' and ename like ''%''||:p_ename||''%''';
else
l_query := l_query ||
' and 1 = DECODE(:p_ename,NULL,1,1)';
end if;

............


and then open the cursor with a fixed number of bind inputs.

Arun Gupta, September 21, 2003 - 10:20 pm UTC

The driving_site hint is also sending the entire query including the where clause to the remote database.

The other alternative won't work because of the number of parameters vary from all possible combinations of 0 to 9. This was the reason we used sys_context in the first place.

The only workaround which seems to work is to replace all occurrences of sys_context() with select sys_context() from dual. Is there any downside to using this ?

This behavior gives rise to another question. When does Oracle populate bind variables in queries issued against a remote database? The bind variable values are user session specific. Thus Oracle should populate bind variables before sending queries to the remote database. If sys_context is treated as a bind variable, shouldn't Oracle evaluate it's value before sending to remote database?

Thanks...

Tom Kyte
September 22, 2003 - 7:26 am UTC

the other altnative DOES work -- you would always have a fixed number of inputs - it would work 100% (it has to, else sys_context would not either!)

selecting from dual works nicely.

If the query is optimized on the remote site, thats where it'll take place with sys_context. sys_context is "like" a bind, it is not a "bind"

Why using sys_context for dynamic sql is slower?

Jap Boon Churn, October 01, 2003 - 3:24 am UTC

Hi Tom,

I was very happy to found this article yesterday and hoping i can apply and use this new technique (sys_context) for my query tuning activity currently.

However, it does not turn out to be satisfying.
I created 2 procedures, exactly the same, except one uses sys_context to assign the parameter value to dynamic sql statement, the other one just put in literal value into the query. Both using oracle text. My database is 8.1.6.

The one not using sys_context finishes query in 1 or 2 seconds for 90 records.

The one using sys_context finishes query in 9 or 10 seconds for 90 records as well.

I feel surprise to see this, cos that's a great difference.

Therefore, would appreciate if you can provide some advice for me, maybe there are some other areas that i miss out.

Would appreciate your followup.
Thanks.

Tom Kyte
October 01, 2003 - 8:36 am UTC

tkprof will show us what the issue is. lets see the tkprof of the two queries.

9.2.0.4 and sys_context

Arun Gupta, October 10, 2003 - 1:09 pm UTC

Tom,
Please see my post above about 9.2.0.4 sending the sys_context to remote database. I opened a TAR with support and development agreed that this was a bug. This will be fixed in the next patchset.
Thanks.

A reader, October 29, 2003 - 10:31 am UTC

ops$tkyte@ORA920> select decode( count(*), 1, 'N', 'Y' )
2 from dual
3 where exists ( select null
4 from loans
5 where loan_key = :loan
6 and ( loan_total = 0
7 or
8 (loan_interest = 0 and loan_category <> 'I')
9 )
10 )
11 /


If we select the above selected value into a variable like the below, then do we need an exception section to handle the no_data_found exception...

ops$tkyte@ORA920> select decode( count(*), 1, 'N', 'Y' )
into lv_variable
2 from dual
3 where exists ( select null
4 from loans
5 where loan_key = :loan
6 and ( loan_total = 0
7 or
8 (loan_interest = 0 and loan_category <> 'I')
9 )
10 )
11 /


Tom Kyte
October 29, 2003 - 11:24 am UTC

an aggregate without a group by ALWAYS returns at least one row - and at most one row.

No exception handling needed -- you'll never get too_many_rows nor no_data_found.


ops$tkyte@ORA920LAP> select count(*) from dual where 1=0;

  COUNT(*)
----------
         0

1 row selected.

ops$tkyte@ORA920LAP> select max(1) from dual where 1=0;

    MAX(1)
----------


1 row selected.
 

cursor count

mo, December 03, 2003 - 4:35 pm UTC

Tom:

AS a followup to how to count records and print total in an implicit cursor you said to use rownum or count them.

For x in (select * from emp where soundex(last_name)= soundex(i_last_name) )
LOOP

END LOOP;

IF I count in the loop then I would not be able to print the total before the result set like "Total Matches: 6" and then print them.

I do not see how rownum will five me the total.

Do I have t orun a separate count before I print the result set?

Thank you

Tom Kyte
December 03, 2003 - 6:54 pm UTC

don't print the total "first" would be *my* answer

otherwise, you have to fetch all of the rows, and THEN print them.

if the result set is "small" enough (less then hundreds) then


select * BULK COLLECT into ...
from emp
where ....;


will work -- you'll fill up array(s) of data, which you can use the .count attribute on to see "how many" and then print.

count

mo, December 04, 2003 - 10:53 am UTC

Tom:

Is this "BULK COLLECT" new feature in 9i?

Do you mean to use it instead of using implicit cursor since it allows me to do counts?

Thank you,

Tom Kyte
December 04, 2003 - 11:14 am UTC

no, it was in 8i as well.


i'm saying "don't use it, put the count at the bottom (bottom, top, side, -- who cares really)"

but if you feel compelled to print it
and the result set is smallish (hundreds at most)
bulk collect it and you can use the .count attribute on the arrays to see "how many there are"


ops$tkyte@ORA815> declare
  2      type array is table of varchar2(2000) index by binary_integer;
  3
  4      l_ename array;
  5      l_empno array;
  6  begin
  7      select ename, empno bulk collect into l_ename, l_empno
  8        from scott.emp;
  9
 10      dbms_output.put_line( l_ename.count || ' rows selected' );
 11
 12      for i in 1 .. l_ename.count
 13      loop
 14          dbms_output.put_line( l_ename(i) || ',' || l_empno(i) );
 15      end loop;
 16  end;
 17  /
16 rows selected
A,7369
ALLEN,7499
WARD,7521
JONES,7566
MARTIN,7654
BLAKE,7698
CLARK,7782
SCOTT,7788
KING,7839
TURNER,7844
ADAMS,7876
JAMES,7900
FORD,7902
MILLER,7934
ant,999
ant,9999
 
PL/SQL procedure successfully completed.
 

set context

mo, December 15, 2003 - 9:59 am UTC

Tom:

I am trying to build a ref cursor as this. Either fo a soundex search on last name, or do a last name character search or both.

dbms_session.set_context('LN_CTX','LAST_NAME',i_last_name);

IF (i_soundex_search = 'Y' and i_lname_search is null ) THEN
open l_cursor for select * from applicant where soundex(last_name) = soundex(i_last_name);
elsif ( i_soundex_search is null and i_lname_search = 'Y' ) THEN
open l_cursor for select * from applicant where last_name like sys_context('LN_CTX','LAST_NAME');
elsif ( i_soundex_search is null and i_lname_search = 'Y' ) THEN
open l_cursor for select * applicant where soundex(last_name) = soundex(i_last_name)
or last_name like sys_context('LN_CTX','LAST_NAME');
END IF;

1. I keep getting an error:
Mon, 15 Dec 2003 14:37:52 GMT

ORA-01031: insufficient privileges
ORA-06512: at "SYS.DBMS_SESSION", line 78
ORA-06512: at "IDEV.DDS_APPLICANT", line 1246
ORA-06512: at line 10

DBA says he gave access to IDEV on DBMS_SESSION and when I log in as IDEV and do desc dbms_session i get results.

This is a 9i database. Do you know what is the problem?

2. When you build a query and want to use "like" it seems you do not have to use "%" and the bind does it automatically? Is this correct.

3. Is these any other way to build ref cursor and bind variables without dbms_session.

Thank you,

Tom Kyte
December 15, 2003 - 10:13 am UTC

1) A context is created bound to a package or procedure:

create or replace context LN_CTX using <procedure>;

ONLY that procedure is allowed to set it, this error indicates you are not setting it in the procedure it was defined with. It is not anything to do with dbms_session -- you are "privileged" to run dbms_session (the error is INSIDE of dbms_session -- if you weren't allowed to run it, the error wouldn't be INSIDE of it!)

2) that is not correct. if you want a % you better add a %, else there will be no %

3) look at Darko Egersdorfer's comment above.

set context

mo, December 15, 2003 - 11:35 am UTC

Tom:

I do login to sql*plus using IDEV account and run

SQL> create or replace context ln_ctx using dss_applicant.find_applicant
/
Context Created.

The name of my package is "DSS_APPLICANT".

The name of my procedure is "FIND_APPLICANT".

I still get the error.

Mon, 15 Dec 2003 16:27:36 GMT

ORA-01031: insufficient privileges
ORA-06512: at "SYS.DBMS_SESSION", line 78
ORA-06512: at "IDEV.DSS_APPLICANT", line 1246
ORA-06512: at line 10

2.  How do you insert the "%" with the bind variable.

do you do like this:

open l_cursor for select * from emp where lname like :last_name ||'%'

Thank you, 

Tom Kyte
December 15, 2003 - 3:48 pm UTC

that is wrong. the "using" is either the

a) name of a package
b) name of a procedure (standalone)

you've just create a context that can be modified by a package (any function or procedure in that package) or standalone procedure in the schema DSS_APPLICANT

I thing you just want to say "using dss_applicant"

ref cursor

mo, December 17, 2003 - 11:22 am UTC

Tom:

You are right. Context should be created using package.

1. If I want to use an index in my search for this cursor Would I just create a function based index on soundex(Last_name). How about the 2nd and 3rd if clause when I want to search by either soundex or like last name.

dbms_session.set_context('LN_CTX','LAST_NAME',lower(i_last_name));
IF (i_soundex_search = 'Y' and i_lname_search is null ) THEN
open l_cursor for select * from applicant where soundex(last_name) = soundex(i_last_name);
elsif ( i_soundex_search is null and i_lname_search = 'Y' ) THEN
open l_cursor for select * from applicant where lower(last_name) like sys_context('LN_CTX','LAST_NAME')||'%';
elsif ( i_soundex_search ='Y' and i_lname_search = 'Y' ) THEN
open l_cursor for select * from applicant where soundex(last_name) = soundex(i_last_name) or
lower(last_name) like sys_context('LN_CTX','LAST_NAME')||'%';
END IF;



Tom Kyte
December 18, 2003 - 8:38 am UTC

looks like you really might want a TEXT index on this (support the like, keyword matches, soundex, fuzzy searches, etc)

but -- yes, a b*tree index on soundex would let the first query use an index

a b*tree index on lower(last_name) would let the second

and the third, could, if appropriate, use both.

reader, December 29, 2003 - 5:17 am UTC

Presently we have code which uses cursor as follows

procedure sample
declare
cursor c1 is select ....
begin
for rs in c1
loop
processing;
end loop;
end;

now the query for cursor has to be dynamic, the values in list will be selected from a table and the query string be formed so I am thinking of this way
just an example

declare
lemp emp.empno%type;
type emprec is ref cursor;
c1 emprec;
lstring varchar2(200) := 'select * from emp where empno in';
begin
lstring := lstring || '(999,888)';
open c1 for lstring;
loop
fetch c1 into lemp;
dbms_output.put_line(lemp);
exit when c1%notfound;
end loop;
close c1;
end;


I would like to have your suggestion on this is this ok to go with or should I use dbms_sql. Please suggest.

Thanking you as always for all your help.

Best Regards.

Tom Kyte
December 29, 2003 - 10:32 am UTC

USE BIND VARIABLES

do not, repeat, do not even consider this approach.

either

a) search this site for

varying in list

to see a technique that'll let you bind a comma delimited list

b) use a global temporary table, insert the values from the list into the gtt and then query using "where empno in (select * from gtt)"


In short -- stick with STATIC SQL, use BIND VARIABLES.

Thanks Tom for your help

reader, December 30, 2003 - 5:40 am UTC

Hi Tom,
Good day to you, well learning from you by your site and book I can't make the mistake of ignoring bind variables, but I didn't gave proper example sorry for that. I am a little confused with your last sentence "In short -- stick with STATIC SQL, use BIND VARIABLES" if I am getting it right do you mean the cursor definition should be like this
Cursor c1 is select * from emp where empno in (select empno from tempemp), if I am wrong please do correct me, also this is just one condition there will be other conditions too depending on the values in a table those have to be incorporated in the query so in this case how should it be done.

Thanks again for your time and help.

Best Regards.


Tom Kyte
December 30, 2003 - 10:21 am UTC

that is great

select *
from emp
where empno in ( select empno from gtt );


if you have to dynamically build the predicate, then yes, you will have to use dynamimc sql -- see the technique outlined in the original answer above.



Valar, January 22, 2004 - 11:34 am UTC

Hi Tom, Thanks for the simple and precise example of using an application context and sys_context functions. Sounds like a good use when the predicate clause is dynamic. I am trying to use this approach for one of my problems. My question here is, would you use the same method to build the predicate clause, if there are 40 input variables to the procedure.

My procedure would be something like the following,

create or replace context dem_ctx using sp_getqueryresults;

create or replace procedure sp_getqueryresults
(p_lastname dem.lastname%type default null, -- Search condition1
p_firstname dem.firstname%type default null,
p_dob dem.dob%type default null,
p_height dem.height%type default null,
p_eyecolor dem.eyecolor%type default null,
p_haircolor dem.haircolor%type default null,
...
...
p_address1 dem.address1%type default null -- Search condition 40

)
is
type rc is REF CURSOR;

t_demcursor rc;
t_query varchar2(5000)
default 'select a.demid a.lastname, a.firstname, a.dob, a.createdate from dem a where 1=1';

cursor t_template is select * from dem;
t_demrec t_template%rowtype;

begin
-- Check for lastname
if p_lastname is not null then
dbms_session.set_context( 'DEM_CTX', 'LASTNAME','%'||upper(p_lastname)||'%');
t_query := t_query || ' and lastname like sys_context( ''DEM_CTX'', ''LASTNAME'' ) ';
dbms_output.put_line('Inside lastname');
end if;

-- Check for firstname
if p_firstname is not null then
dbms_session.set_context( 'DEM_CTX', 'FIRSTNAME','%'||upper(p_firstname)||'%');
t_query := t_query || ' and firstname like sys_context( ''DEM_CTX'', ''FIRSTNAME'' ) ';
dbms_output.put_line('Inside firstname');
end if;


/* Code for search criteria 3 upto search criteria 39

...
...
*/

-- Check for address1
if p_address1 is not null then
dbms_session.set_context( 'DEM_CTX', 'ADDRESS1',p_address1);
t_query := t_query ||' and contains(address1, sys_context( ''DEM_CTX'', ''ADDRESS1'' )) > 0';
dbms_output.put_line('Inside address1');
end if;

p( t_query);

open t_demcursor for t_query;
loop
fetch t_demcursor into t_demrec;
exit when t_demcursor%notfound;

dbms_output.put_line( t_demrec.demid || ',' ||
t_demrec.lastname || ',' ||
t_demrec.firstname );
end loop;

close t_demcursor;
end;
/


Looking at the above code, you would find that for the different search criteria, we have to code atleast 40 "if-end if " blocks. Could you please suggest ways to refine/minimise the above code ? My search conditions involve number, date parameters, textdata (using contains) and also inlist type of variables.

Thanks,
Valar

Tom Kyte
January 22, 2004 - 7:39 pm UTC

depends - here I might - MIGHT -- consider a text index and index an XML representation of that row and use "contains" with section searching as I doubt you'd index everything otherwise.

Valar, January 26, 2004 - 5:29 pm UTC

Thanks for the last follow-up. You are right that almost all search fields are indexed. We are looking at atleast 35 individual indexes or so. I was further reading on to see what the options of storing in xml are and how section indexing worked. It's obvious if we go for such an option, we would have to store the demographic data pertaining to each row in a seperate column in the dem table. Is that right ? (I think the answer would be 'Yes', as the data is currently stored in seperate columns in the dem table.)

Before going more into that, I would like to know, what might influence your decision to go for an xml representation with section searching ? Is it the volume of data in the dem table or is it the type of transactions involved in the dem table or Is it the required performance of search query ?

Currently this search procedure sp_getqueryresults is intended to provide core functionality for one of our searching Components which should serve a wide range of customers. The demographic records to search vary by each customer. The lowest volume of records to be searched is 300,000 and the highest is 15 million or so. We have to come up with a possible package/procedure to serve the varied customer base and provide efficient searching. The type of transactions involved are mostly 'insert-only'. Of course there are a few update transactions to delink records, which have been linked due to mistyped customer number/ssn and so forth. Should we plan such that we need to come up with different search routine packages/procedures depending upon the volume of data or so ? Any other suggestions/pointers ? Please let us know.
Thanks,
Valar


Tom Kyte
January 26, 2004 - 5:56 pm UTC

it would be all about retrieval. You want to search on N of M fields where N is always changing. I'd like to have a single index.

sp_, hmmm, a sqlserver stored procedure in disguise ;)

I would use the technique of indexing a function -- store the data relationally, but index an xml representation of it (very close to what I do on asktom here. I index "web pages" but the data is stored in 3 tables with master /detail /detail relationships. I index a "function" that returns the formatted page so you think you are searching pages -- but you are really searching many rows across many tables)

You would use the same technique for 1 row, or 15 billion rows.

Valar, January 27, 2004 - 9:10 am UTC

Thanks for pointing towards the technique of indexing a function and probably using a single index rather than N number of indexes. Shall look further into this approach and apply to this problem.

Regards usage of sp_, it so happened that in the place where I work, the usual convention for referencing a stored procedure is sp_ and for packages it is pack_. Here we do projects both in SQL Server and Oracle, so it's been like that.


Thanks again !!
Valar

Valar, January 28, 2004 - 2:58 pm UTC

Tom,

Based on your follow-up, I tried to generate an xml representation of a simplistic dem table. Attached below are the sql outputs for the same. The create context index scripts was throwing up an error and I wasn't sure, if I was on the right path. Can you please suggest on this ? Thanks,
Valar
CTDLDBO@CTDL:CTTESTCIS> create table dem
2 ( demid number,
3 lastname varchar(25),
4 firstname varchar(10),
5 address1 varchar(30)
6 )
7 tablespace data;

Table created.

CTDLDBO@CTDL:CTTESTCIS>
CTDLDBO@CTDL:CTTESTCIS>
CTDLDBO@CTDL:CTTESTCIS> insert into dem
2 values (1,'MCDERMOTT', 'JIM', '30 Boston Road');

1 row created.

CTDLDBO@CTDL:CTTESTCIS>
CTDLDBO@CTDL:CTTESTCIS> insert into dem
2 values (2,'G', 'VALAR', '50 Kendall Square');

1 row created.

CTDLDBO@CTDL:CTTESTCIS>
CTDLDBO@CTDL:CTTESTCIS> insert into dem
2 values (3,'SMITH', 'BOB', '25 Taylor Street');

1 row created.

CTDLDBO@CTDL:CTTESTCIS> commit;

Commit complete.

CTDLDBO@CTDL:CTTESTCIS>
CTDLDBO@CTDL:CTTESTCIS>
CTDLDBO@CTDL:CTTESTCIS> create or replace package pack_testgenxml
2 as
3 function fn_gendemxml return clob DETERMINISTIC;
4 end;
5 /

Package created.

CTDLDBO@CTDL:CTTESTCIS>
CTDLDBO@CTDL:CTTESTCIS>
CTDLDBO@CTDL:CTTESTCIS> create or replace package body pack_testgenxml
2 as
3
4 function fn_gendemxml return clob
5 is
6 tqueryctx dbms_xmlquery.ctxtype;
7 tempdata clob;
8 begin
9 tqueryctx := DBMS_XMLQuery.newContext('select * from dem');
10 tempdata := dbms_xmlquery.getxml(tqueryctx);
11 DBMS_XMLQuery.closecontext(tqueryctx);
12 return tempdata;
13 end;
14 end;
15 /

Package body created.

CTDLDBO@CTDL:CTTESTCIS>
CTDLDBO@CTDL:CTTESTCIS> set autoprint on
CTDLDBO@CTDL:CTTESTCIS> variable x clob;
CTDLDBO@CTDL:CTTESTCIS> exec :x := pack_testgenxml.fn_gendemxml()

PL/SQL procedure successfully completed.


X
--------------------------------------------------------------------------------
<?xml version = '1.0'?>
<ROWSET>
<ROW num="1">
<DEMID>1</DEMID>
<
LASTNAME>MCDERMOTT</LASTNAME>
<FIRSTNAME>JIM</FIRSTNAME>
<ADDRESS1>3
0 Boston Road</ADDRESS1>
</ROW>
<ROW num="2">
<DEMID>2</DEMID>

<LASTNAME>G</LASTNAME>
<FIRSTNAME>VALAR</FIRSTNAME>
<ADDRESS1>50 Ke
ndall Square</ADDRESS1>
</ROW>
<ROW num="3">
<DEMID>3</DEMID>

<LASTNAME>SMITH</LASTNAME>
<FIRSTNAME>BOB</FIRSTNAME>
<ADDRESS1>25 T
aylor Street</ADDRESS1>
</ROW>
</ROWSET>


CTDLDBO@CTDL:CTTESTCIS>
CTDLDBO@CTDL:CTTESTCIS> create index idx_dem_fngendemxml on dem(pack_testgenxml.fn_gendemxml())
2 indextype is ctxsys.context;
create index idx_dem_fngendemxml on dem(pack_testgenxml.fn_gendemxml())
*
ERROR at line 1:
ORA-29958: fatal error occurred in the execution of ODCIINDEXCREATE routine
ORA-29960: line 1,
DRG-11304: function-based indexes are not supported by this indextype


CTDLDBO@CTDL:CTTESTCIS> select * from v$version;

BANNER
----------------------------------------------------------------
Oracle9i Enterprise Edition Release 9.0.1.1.1 - Production
PL/SQL Release 9.0.1.1.1 - Production
CORE 9.0.1.1.1 Production
TNS for 32-bit Windows: Version 9.0.1.1.0 - Production
NLSRTL Version 9.0.1.1.1 - Production

CTDLDBO@CTDL:CTTESTCIS>

Tom Kyte
January 29, 2004 - 7:37 am UTC

see

</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:440419921146 <code>

that demonstrates how to index a function with TEXT.

What I do is I have three tables:

create table parent
create table detail1;
create table detail2;

and on detail1 and detail2 I put a trigger that touches parent with an update when they are updated. the index is on the parent table and it assembles (based on it's primary key) the data from parent and detail1/detail2 and that is what text indexes.

Thanks

Valar, January 29, 2004 - 10:57 pm UTC

Tom, The link to the text index creation proved to be very useful. I was able to index a text representation of an xml output. I like the way you give such explanatory examples and share your knowledge with the Oracle community.

-Valar

bind variables??

dwl, February 20, 2004 - 7:01 am UTC

Tom

This thread has proved very interesting to me and very useful.
I understand that we need to use bind variables. My procedure is below. As you can see
i'm using several of your techniques!
I use your str2tble function to pass in a varying array of interger to the procedure to run.

However can you just explain if/why the second version of the same procedure does not use bind variables? All
the second version does is remove the sys_context call and replace it with the bind variable:



PROCEDURE P_Get_SBE_ST ( P_Return_Date IN SBE_TABLEA.RETURN_DATE%TYPE,
P_Org_String IN VARCHAR2 DEFAULT NULL,
P_Cur IN OUT C_Return_Cursor )


IS


l_query varchar2(2000)
default 'SELECT :P_Return_Date,
o.Org_Id,
o.Organisation_Code,
CURSOR(SELECT RETURN_DATE,
PAYMENT_ORG_ID,
T1_ST_COUNT,
T2_OO_FULL,
T2_OO_PART,
T2_OMP_FULL,
T2_OMP_PART,
T2_TOTAL_OO,
T2_TOTAL_OMP,
T2_TOTAL_FULL,
T2_TOTAL_PART,
T2_TOTAL_DOM,
T3_OO_ALL,
T3_OMP_ALL,
T3_TOTAL,
T5A_ST_COUNT,
T5B_DOM_COUNT
FROM SBE_TABLEA
WHERE Payment_Org_ID = o.Org_ID
AND Return_Date = :P_Return_Date) AS TABLEA,
CURSOR(SELECT RETURN_DATE,
PAYMENT_ORG_ID,
REASON,
REASON_COUNT,
REASON_DESCRIPTION
FROM SBE_TABLE4
WHERE Payment_Org_ID = o.Org_ID
AND Return_Date = :P_Return_Date) AS TABLE4
FROM ORGANISATION o
WHERE Type_Id IN (5, 7, 10)';



BEGIN



IF ( P_Org_String IS NOT NULL ) THEN

DBMS_SESSION.SET_CONTEXT( 'MY_CTX', 'ORG_STRING', P_Org_String);
l_query := l_query ||' AND o.Org_ID IN ( SELECT *
FROM THE ( SELECT CAST( str2tbl( sys_context( ''MY_CTX'', ''ORG_STRING'' ) ) as tbl_Numbers ) from dual ) ) ';

END IF;

open P_Cur for l_query USING P_Return_Date,
P_Return_Date,
P_Return_Date;



END P_Get_SBE_ST ;




The following is a copy of the above without using the context method:
(P_Org_String just contains a string such as '1, 2, 3, 4, 5')




PROCEDURE P_Get_SBE_ST ( P_Return_Date IN SBE_TABLEA.RETURN_DATE%TYPE,
P_Org_String IN VARCHAR2 DEFAULT NULL,
P_Cur IN OUT C_Return_Cursor )


IS


l_query varchar2(2000)
default 'SELECT :P_Return_Date,
o.Org_Id,
o.Organisation_Code,
CURSOR(SELECT RETURN_DATE,
PAYMENT_ORG_ID,
T1_ST_COUNT,
T2_OO_FULL,
T2_OO_PART,
T2_OMP_FULL,
T2_OMP_PART,
T2_TOTAL_OO,
T2_TOTAL_OMP,
T2_TOTAL_FULL,
T2_TOTAL_PART,
T2_TOTAL_DOM,
T3_OO_ALL,
T3_OMP_ALL,
T3_TOTAL,
T5A_ST_COUNT,
T5B_DOM_COUNT
FROM SBE_TABLEA
WHERE Payment_Org_ID = o.Org_ID
AND Return_Date = :P_Return_Date) AS TABLEA,
CURSOR(SELECT RETURN_DATE,
PAYMENT_ORG_ID,
REASON,
REASON_COUNT,
REASON_DESCRIPTION
FROM SBE_TABLE4
WHERE Payment_Org_ID = o.Org_ID
AND Return_Date = :P_Return_Date) AS TABLE4
FROM ORGANISATION o
WHERE Type_Id IN (5, 7, 10)';



BEGIN



IF ( P_Org_String IS NOT NULL ) THEN

l_query := l_query ||' AND o.Org_ID IN ( SELECT *
FROM THE ( SELECT CAST( str2tbl( :P_Org_String ) as tbl_Numbers ) from dual ) ) ';

END IF;

open P_Cur for l_query USING P_Return_Date,
P_Return_Date,
P_Return_Date,
:P_Org_String;



END P_Get_SBE_ST ;




I know you cannot run these procedures standalone but i am interested in the reasons behind if/why method
2 does not use the bind variable P_Org_String, since it does use the bind variable :P_Return_Date (or at least
i hope it does!!) ??

Many thanks



Tom Kyte
February 20, 2004 - 9:59 am UTC

both use binds fully.

Confused

dwl, February 24, 2004 - 6:13 am UTC

Ok then so if both methods use binds then i don't understand the use of sys_contexts. I followed the other threads and examples from your book, and utilised (i thought) the use of sys_context in the same way that you did. So why do i not need to use it here, if binds are used by my 2nd method what is the use of sys_context?? Why did you use it in your methods and not do what i did in my 2nd method??

Please explain i am getting confused here!

Tom Kyte
February 24, 2004 - 8:18 am UTC

it is a matter of compile time binding versus runtime binding.

Say you have a routine that accepts a query. It can be ANY query on earth. It wants to use binds, you want to use native dynamic sql ( execute immediate or open p_refcursor for ).

Well, you don't know at compile time whether it'll have 0, 1, 2, .... 1000 binds right -- so you cannot code:

open p_cursor for l_variable using A, B, C;

cause you don't know how many A, B, C's you'll need. so the guy that sends you the query can pass:

select * from emp where ename like sys_context( 'my_ctx', 'ename_like' );

and would call dbms_session.set_context to put a value for ename like in there.



Now, say you have a routine that takes a query and wants to return rows N thru M.

Now, you might code:

open p_cursor for
'select * from ( select a.*, rownum r from ( ' || their_query || ' ) a where rownum <= :m ) where r >= :n' using l_max_row, l_min_row;


there, their query might use SYS_CONTEXT to bind dynamically, you use "static" compile time binds -- since you know how many you have.


It is just different ways to achieve the same end goal. static, compile time binding is easier (less obscure) but doesn't give you the flexibility to bind 1, 2, 3 or 4 things depending on what you need at runtime (sys_context however does)



Mihail Bratu, March 05, 2004 - 8:02 am UTC


thanks but....

dwl, March 09, 2004 - 4:50 am UTC

Tom

Thanks for the reply above. I think i understood what you meant here about compile time and runtime binding, until that is i read this post:

</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:4473634500618, <code>

in there you advise the guy Boris that his code is not using bind variables since he has coded things like:

IF p_sname <>'' THEN
IF p_searchname='1' THEN
SQLQuery := SQLQuery || ' AND ACCOUNT_NAME LIKE '''|| p_sname ||
'%''';


but surely p_sname is a bind variable isn't it? In that post you advised him to change to sys_context as in:


if ( p_sname is NOT NULL ) then
IF p_searchname='1' THEN
dbms_session.set_context( 'MY_CTX', 'ACCOUNT_NAME',
''||p_sname||'%');
l_query := l_query ||
' and ACCOUNT_NAME like
sys_context( ''MY_CTX'', ''ACCOUNT_NAME'' ) ';


But why? Don't both methods use binds?? I appreciate that sys_context maybe the preferred better method but doesn't his first way still bind ?

Thanks

Tom Kyte
March 09, 2004 - 11:40 am UTC

No, p_sname is a variable that they were using to build a string that looked like:

and accountname like 'SMITH%'


In PLSQL if

a) you use static sql -- eg: "for x in ( select ....", "open CURSOR_NAME" -- it is impossible to NOT USE binds (static sql = always bound correctly = best thing)

b) you use DYNAMIC sql -- as they were in that example -- you must be careful to bind, either using "execute immediate statement_in_a_string using BIND_VARIABLE...." or using that sys_context trick

how are ref cursors implemented?

A reader, March 24, 2004 - 3:30 pm UTC

How is that using a ref cursor I can have a pointer
in my java client (say using JDBC for the sake of
example) to a shared pool where
sql cursors are stored?

Can you give a feel of how this may be implemented?
what happens (step by step) when we say
resultSet.next() to move the pointer in memory?

thanx!

Tom Kyte
March 24, 2004 - 4:26 pm UTC

ref cursors are implemented the same as any cursor. It takes more than a couple of sentences to explain -- if you are really interested, I do go into this in detail in either of

Effective Oracle By Design
Beginning Oracle Programming.

but you are pointing at an execution plan in the shared pool, the data is processed by the dedicated or shared server (not in the 'sga'). cursors live in the session -- not the shared pool. the shared pool has parsed queries and their plans.

As as for "what happens" when you got resultset.next() -- it "depends", it totally depends. But, at the end of the day -- you get your row.

How does exists work

A reader, March 25, 2004 - 7:12 pm UTC

SQL> ED
Wrote file afiedt.buf

  1  SELECT ENAME, EMPNO, SUM(SAL)
  2  FROM EMP
  3  WHERE EXISTS( SELECT NULL FROM DEPT
  4                   WHERE EMP.DEPTNO=DEPT.DEPTNO
  5                   AND EMP.DEPTNO=30)
  6* GROUP BY ENAME, EMPNO
SQL> /

ENAME           EMPNO   SUM(SAL)
---------- ---------- ----------
WARD             7521       1250
ALLEN            7499       1600
BLAKE            7698       2850
JAMES            7900        950
MARTIN           7654       1250
TURNER           7844       1500

In the above why is it that I'm not agetting a too many rows error.

Further in the below, I just want to check for the existenc e of deptno 30 in the emp table, but using exists it is returning 6 rows. I read on your web site that exists will check for the first instance of the existance of the row for which we are validating and it returns. In that case I need to return only 1 row..

Wrote file afiedt.buf

  1  SELECT 'X'
  2  FROM EMP
  3  WHERE EXISTS( SELECT NULL FROM DEPT
  4                   WHERE EMP.DEPTNO=DEPT.DEPTNO
  5*                  AND EMP.DEPTNO=30)
  6  /

'
-
X
X
X
X
X
X

6 rows selected.

Please explain.
 

Tom Kyte
March 25, 2004 - 9:37 pm UTC

where exists by its very very definition cannot get too many rows. it looks for the first one and STOPS (where exists -- stop when you see something exists...)

the subquery stops -- the query itself does not (that would be a bug)

if you just want the first random row, add "and rownum = 1"

A reader, March 26, 2004 - 8:09 am UTC

If that is the case then why is the above query returning 6 rows. Shouldnt it return only one row, OR is it that it is checking for the existence of dept 30 once for each row returned by the outer query?

In the above query, if EMP has 1000 rows, and if deptno happens to be at rows 1, 100, and 500 will I be scanning the whole table for each row. How does it work.

Tom Kyte
March 26, 2004 - 9:33 am UTC

the query:

select * from t where exists ( subquery )

is conceptually like this:


for x in ( select * from t )
loop
IF the subquery returns at least one row
then
OUTPUT X
end if
end loop


where exists checks each row in the outer query -- just like:


select * from t where x=5;

checks each row for "x=5", each row is checked to see if a row in the subquery "exists"


where exists is really not different from "x=5" in that context. It is just a predicate applied to a row.

Cursor bug

Fan from Germany, March 26, 2004 - 4:56 pm UTC

Hi Tom,

Recently our database has crashed having problem with memory (Oracle v9.2). Oracle support gave us an answer telling that we have hit oracle bug when a query (cursor) in DB procedure accessing partitioned table use function new_time and cursor_sharing is enabled => raise ORA-600.
But to me this look quite strange. To describe:
cursor_sharing is set to exact, query itself does not use function new_time (procedure does) and system crashes only when in query where clause we use one particular column (in that case query have a cost of 5000).
If we execute the same query under the same conditions but use another column (in this case query have cost of 500 and return the same result set) system does not crash.
In both cases query (actually cursor) use bind variables.
I have checked shared pool in second case and query has been parsed once and executed 120 times. In first case is the same but only difference is cost...query takes longer to finish.
This is confusing to me. If the bug is presistent, system will chrash in both cases.
Does the query execution time play some role in this bug and could you please give me some more information about this oracle bug if you have?
I do not know wheter my explanation was clear, but if you need some more detailed info, I can post it.

Tom Kyte
March 26, 2004 - 6:53 pm UTC

so, your database isn't crashing, a session is getting an ora-600 with cursor_sharing...


but you say you are not using that -- so obviously -- support has either

a) misdiagnosed the issue
b) failed to explain that the but can happen due to other reasons.


without having access to the actual bug number and tar related information -- i'd be hard pressed to really "say more"

very informative

Susan, March 29, 2004 - 1:31 pm UTC

Tom,

I have a situation that sounds appropriate for ref cursors but would like your thoughts on the suggested design. We have certain table rows that only certain users should be able to view. We access all of these rows through a view. I've implemented a FGAC method of controlling who sees what. Now, my manager wants to add a permissions flag column on the view that will contain a string value for all permission types (add, edit, browse, delete, settomissing). The application gets the string value and provides the appropriate access. The goal is to keep the logic of the permission flagging in a table (most of our developers don't know pl/sql that well) and have a package that can dynamically create the where statement based on the values (or lack of values) in the table. The logic will involve other tables (eg. form fm01 can be browsed by (select user_id from users where site_id> 100), so we'll be using parameters. We're aiming to keep it flexible so that a form could have multiple conditions regarding the same permission type. I think ref cursors might be the approach here, but, this is a little different in that the logic is table driven. Thanks for any suggestions.

Tom Kyte
March 29, 2004 - 1:56 pm UTC

well, if you are using ref cursors to build a small finite set of performant SQL queries......

instead of trying to use one huge generic "one size fits all query" that might be not so performant.....

based on some inputs and maybe whose logged in currently, that works for me.



Must create context after package is completely defined.

Jim Nasby, March 29, 2004 - 3:52 pm UTC

This just baffled me for a while... If you do something like:

CREATE PACKAGE foo AS
...

CREATE CONTEXT ctx_foo USING foo;

CREATE PACKAGE BODY foo AS
...

You will get

ORA-01031: insufficient privileges
ORA-06512: at "SYS.DBMS_SESSION", line 78

If you follow the exact procedure in the docs though, which is to create the package AND package body, then create the context, it will work fine.

Tom Kyte
March 29, 2004 - 4:24 pm UTC

give us a full "for example"

you can create the context and then everything else

you can create everything else and then the context

you can mix them in any order you want.....

(must have been a typo in your code I'm guessing...)



ops$tkyte@ORA9IR2> create package foo
  2  as
  3          procedure p;
  4  end;
  5  /
 
Package created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> create context ctx_foo using foo
  2  /
 
Context created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> create package body foo
  2  as
  3
  4  procedure p
  5  is
  6  begin
  7          dbms_session.set_context( 'ctx_foo', 'x', 55 );
  8  end;
  9
 10  end;
 11  /
 
Package body created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> exec foo.p
 
PL/SQL procedure successfully completed.
 

Wonder

Arangaperumal, March 30, 2004 - 5:59 am UTC

I really wonder about the techniques you are
using.



dynamic where

mary w, April 14, 2004 - 3:58 pm UTC

Trying to do dynamic where. i pass var through java into sored proceduer and back to webpage. but get error ref cursor is invalid.

can u see if something is wrong right away?

--thanks



CREATE OR REPLACE PACKAGE LOCATION_SEARCH


AS

TYPE CURSOR_TYPE IS REF CURSOR;

/*-----------------------------------------------------------------------------------------*/
PROCEDURE calculate_distance_by_zip
(in_zip_code IN NUMBER,
in_radius IN NUMBER,
oresult_set IN OUT CURSOR_TYPE);
/*-----------------------------------------------------------------------------------------*/
PROCEDURE get_search_results
(in_city IN varchar2,
in_state IN varchar2,
in_zip IN varchar2,
in_radius IN NUMBER,
oresult_set IN OUT CURSOR_TYPE);

END LOCATION_SEARCH;
/

CREATE OR REPLACE PACKAGE BODY LOCATION_SEARCH AS


/*-----------------------------------------------------------------------------------------*/
PROCEDURE calculate_distance_by_zip
(in_zip_code IN NUMBER,
in_radius IN NUMBER,
oresult_set IN OUT CURSOR_TYPE)
IS

BEGIN



open oresult_set for

select di.DEALER_NAME, di.DEALER_ADDRESS1, di.DEALER_ADDRESS2, di.DEALER_CITY, di.DEALER_STATE,di.DEALER_ZIP,
di.DEALER_PHONE, di.DEALER_FAX, di.DEALER_URL_LINK, di.brand1, di.brand2, di.brand3, zd.DISTANCE
from xmr.dealer_information di, xmr.zip_distance zd
where dealer_zip = zd.ZIP_CODE_to
and distance <= in_radius
and zip_code_from = in_zip_code
order by dealer_name, distance;



END calculate_distance_by_zip;



/*-----------------------------------------------------------------------------------------*/

PROCEDURE get_search_results
(in_city IN varchar2,
in_state IN varchar2,
in_zip IN varchar2,
in_radius IN NUMBER,
oresult_set IN OUT CURSOR_TYPE)
IS
sql_by_city_state VARCHAR2(200) := ' ';
BEGIN




--search by city
if in_city !='' and in_state = '' and in_zip= '' then
open oresult_set for

select di.DEALER_NAME, di.DEALER_ADDRESS1, di.DEALER_ADDRESS2, di.DEALER_CITY, di.DEALER_STATE,
di.DEALER_ZIP, di.DEALER_PHONE, di.DEALER_FAX, di.DEALER_URL_LINK, di.brand1, di.brand2,
di.brand3, zd.DISTANCE from dealer_information di, zip_distance zd
where dealer_zip = zd.ZIP_CODE_TO
and distance <= in_radius
and di.DEALER_CITY = in_city;

CLOSE oresult_set;
end if;

--search by state
if in_city ='' and in_state != '' and in_zip= '' then
open oresult_set for

select di.DEALER_NAME, di.DEALER_ADDRESS1, di.DEALER_ADDRESS2, di.DEALER_CITY, di.DEALER_STATE,
di.DEALER_ZIP, di.DEALER_PHONE, di.DEALER_FAX, di.DEALER_URL_LINK, di.brand1, di.brand2,
di.brand3, zd.DISTANCE from dealer_information di, zip_distance zd
where dealer_zip = zd.ZIP_CODE_TO
and distance <= in_radius
and di.DEALER_STATE = in_state;
CLOSE oresult_set;

end if;

--search by city and state
if in_city !='' and in_state != '' and in_zip= '' then
open oresult_set for

select di.DEALER_NAME, di.DEALER_ADDRESS1, di.DEALER_ADDRESS2, di.DEALER_CITY, di.DEALER_STATE,
di.DEALER_ZIP, di.DEALER_PHONE, di.DEALER_FAX, di.DEALER_URL_LINK, di.brand1, di.brand2,
di.brand3, zd.DISTANCE from dealer_information di, zip_distance zd
where dealer_zip = zd.ZIP_CODE_TO
and distance <= in_radius
and di.DEALER_STATE = in_state
and di.DEALER_CITY = in_city;

CLOSE oresult_set;

end if;

-- search by zip code
if in_zip != '' then

open oresult_set for

select di.DEALER_NAME, di.DEALER_ADDRESS1, di.DEALER_ADDRESS2, di.DEALER_CITY, di.DEALER_STATE,
di.DEALER_ZIP, di.DEALER_PHONE, di.DEALER_FAX, di.DEALER_URL_LINK, di.brand1, di.brand2,
di.brand3, zd.DISTANCE from dealer_information di, zip_distance zd
where dealer_zip = zd.ZIP_CODE_TO
and distance <= in_radius
and zip_code_from = in_zip
order by distance, dealer_name;

CLOSE oresult_set;

end if;




END get_search_results;




END LOCATION_SEARCH;
/



Tom Kyte
April 14, 2004 - 4:19 pm UTC

umm, how can you read from a closed cursor? 

why are you closing it -- before even having read from it?

client closes the cursor after client exhausts result set.

also, not sure if ANY of your predicates are "true"

if in_city !='' and in_state = '' and in_zip= '' then


ops$tkyte@ORA9IR2> create or replace procedure p( in_city in varchar2, in_state in varchar2, in_zip in varchar2 )
  2  as
  3  begin
  4          if ( in_city != '' and in_state = '' and in_zip = '' )
  5          then
  6             dbms_output.put_line( 'is true' );
  7          else
  8             dbms_output.put_line( 'is not true' );
  9          end if;
 10  end;
 11  /
 
Procedure created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> exec p( 'x', '', '' )
is not true
 
PL/SQL procedure successfully completed.
 

versus

ops$tkyte@ORA9IR2> create or replace procedure p( in_city in varchar2, in_state in varchar2, in_zip in varchar2 )
  2  as
  3  begin
  4          if ( in_city IS NOT NULL and in_state IS NULL and in_zip IS NULL )
  5          then
  6             dbms_output.put_line( 'is true' );
  7          else
  8             dbms_output.put_line( 'is not true' );
  9          end if;
 10  end;
 11  /
 
Procedure created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> exec p( 'x', '', '' )
is true
 
PL/SQL procedure successfully completed.
 
 

how about this way

mary w, April 14, 2004 - 5:07 pm UTC

i rewrote it. but now getting another error. (SQL not properly ended line 109) cant firgure it out.

seems ok to me.


CREATE OR REPLACE PACKAGE LOCATION_SEARCH


AS

TYPE CURSOR_TYPE IS REF CURSOR;

/*-----------------------------------------------------------------------------------------*/
PROCEDURE calculate_distance_by_zip
(in_zip_code IN NUMBER,
in_radius IN NUMBER,
oresult_set IN OUT CURSOR_TYPE);
/*-----------------------------------------------------------------------------------------*/
PROCEDURE get_search_results
(in_city IN varchar2,
in_state IN varchar2,
in_zip IN varchar2,
in_radius IN NUMBER,
oresult_set IN OUT CURSOR_TYPE);

END LOCATION_SEARCH;
/

CREATE OR REPLACE PACKAGE BODY LOCATION_SEARCH AS


/*-----------------------------------------------------------------------------------------*/
PROCEDURE calculate_distance_by_zip
(in_zip_code IN NUMBER,
in_radius IN NUMBER,
oresult_set IN OUT CURSOR_TYPE)
IS

BEGIN



open oresult_set for

select di.DEALER_NAME, di.DEALER_ADDRESS1, di.DEALER_ADDRESS2, di.DEALER_CITY, di.DEALER_STATE,di.DEALER_ZIP,
di.DEALER_PHONE, di.DEALER_FAX, di.DEALER_URL_LINK, di.brand1, di.brand2, di.brand3, zd.DISTANCE
from xmr.dealer_information di, xmr.zip_distance zd
where dealer_zip = zd.ZIP_CODE_to
and distance <= in_radius
and zip_code_from = in_zip_code
order by dealer_name, distance;



END calculate_distance_by_zip;



/*-----------------------------------------------------------------------------------------*/

PROCEDURE get_search_results
(in_city IN varchar2,
in_state IN varchar2,
in_zip IN varchar2,
in_radius IN NUMBER,
oresult_set IN OUT CURSOR_TYPE)
IS
sql_by_city_state VARCHAR2(400) := ' select di.DEALER_NAME, di.DEALER_ADDRESS1, di.DEALER_ADDRESS2, di.DEALER_CITY,
di.DEALER_STATE,di.DEALER_ZIP, di.DEALER_PHONE, di.DEALER_FAX, di.DEALER_URL_LINK, di.brand1, di.brand2,
di.brand3, zd.DISTANCE from dealer_information di, zip_distance zd where dealer_zip = zd.ZIP_CODE_TO
and distance <= in_radius';

where_clause varchar2(400) :='AND';
BEGIN



--search by city
/*if in_city !='' and in_state = '' and in_zip= '' then
open oresult_set for

select di.DEALER_NAME, di.DEALER_ADDRESS1, di.DEALER_ADDRESS2, di.DEALER_CITY, di.DEALER_STATE,
di.DEALER_ZIP, di.DEALER_PHONE, di.DEALER_FAX, di.DEALER_URL_LINK, di.brand1, di.brand2,
di.brand3, zd.DISTANCE from dealer_information di, zip_distance zd
where dealer_zip = zd.ZIP_CODE_TO
and distance <= in_radius
and di.DEALER_CITY = in_city;


end if;

--search by state
if in_city ='' and in_state != '' and in_zip= '' then
open oresult_set for

select di.DEALER_NAME, di.DEALER_ADDRESS1, di.DEALER_ADDRESS2, di.DEALER_CITY, di.DEALER_STATE,
di.DEALER_ZIP, di.DEALER_PHONE, di.DEALER_FAX, di.DEALER_URL_LINK, di.brand1, di.brand2,
di.brand3, zd.DISTANCE from dealer_information di, zip_distance zd
where dealer_zip = zd.ZIP_CODE_TO
and distance <= in_radius
and di.DEALER_STATE = in_state;


end if;

--search by city and state
if in_city !='' and in_state != '' and in_zip= '' then
open oresult_set for

select di.DEALER_NAME, di.DEALER_ADDRESS1, di.DEALER_ADDRESS2, di.DEALER_CITY, di.DEALER_STATE,
di.DEALER_ZIP, di.DEALER_PHONE, di.DEALER_FAX, di.DEALER_URL_LINK, di.brand1, di.brand2,
di.brand3, zd.DISTANCE from dealer_information di, zip_distance zd
where dealer_zip = zd.ZIP_CODE_TO
and distance <= in_radius
and di.DEALER_STATE = in_state
and di.DEALER_CITY = in_city;



end if;
*/
-- search by zip code
--if in_zip != '' then

if in_city is not null and in_state is null and in_zip is null then
where_clause := where_clause || ' di.DEALER_CITY = '''||in_city||'';
elsif in_city is null and in_state is not null and in_zip is null then
where_clause := where_clause || ' di.DEALER_STATE = '''||in_state||'';
elsif in_city is null and in_state is null and in_zip is not null then
where_clause := where_clause || ' zip_code_from = '''||in_zip||'';
elsif in_city is not null and in_state is not null and in_zip is null then
where_clause := where_clause || ' di.DEALER_CITY = '''||in_city||'';
where_clause := where_clause || ' di.DEALER_STATE = '''||in_state||'';
end if;


open oresult_set for (sql_by_city_state||where_clause);

/*select di.DEALER_NAME, di.DEALER_ADDRESS1, di.DEALER_ADDRESS2, di.DEALER_CITY, di.DEALER_STATE,
di.DEALER_ZIP, di.DEALER_PHONE, di.DEALER_FAX, di.DEALER_URL_LINK, di.brand1, di.brand2,
di.brand3, zd.DISTANCE from dealer_information di, zip_distance zd
where dealer_zip = zd.ZIP_CODE_TO
and distance <= in_radius
and zip_code_from = in_zip
order by distance, dealer_name;
*/


--end if;




END get_search_results;




END LOCATION_SEARCH;
/



Tom Kyte
April 15, 2004 - 7:39 am UTC

please re-read the above discussion where I demonstrate application contexts.

I will not help anyone fix code that doesn't use bind variables like that -- sends chills down my back....


(a little dbms_output.put_line and some testing in sqlplus will be most useful for you -- so you can actually SEE what it is you developed in that string)

but the error is obvious to me and is 100% caused by the lack of you using bind variables. You have an unterminated character string constant in your string. Rather then tell you how to correctly terminate it, i'll insist you do it right with binds!


Here is what I recommend, uncomment the OPEN (note: in_radius needs to be BOUND as i do) to get your refcursor.  Using P you can "debug" your code in sqlplus (make sure serveroutput is ON)


ops$tkyte@ORA9IR2> create or replace package my_pkg
  2  as
  3      type cursor_type is ref cursor;
  4
  5      PROCEDURE get_search_results
  6      (in_city     IN varchar2,
  7       in_state    IN varchar2,
  8       in_zip      IN varchar2,
  9       in_radius   IN NUMBER,
 10       oresult_set IN OUT CURSOR_TYPE);
 11  end;
 12  /
 
Package created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> create or replace context my_ctx using my_pkg
  2  /
 
Context created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> create or replace procedure p ( p_str in varchar2 )
  2  is
  3     l_str   long := p_str;
  4  begin
  5     loop
  6        exit when l_str is null;
  7        dbms_output.put_line( substr( l_str, 1, 250 ) );
  8        l_str := substr( l_str, 251 );
  9     end loop;
 10  end;
 11  /
 
Procedure created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> create or replace package body my_pkg
  2  as
  3
  4  PROCEDURE get_search_results
  5  (in_city     IN varchar2,
  6   in_state    IN varchar2,
  7   in_zip      IN varchar2,
  8   in_radius   IN NUMBER,
  9   oresult_set IN OUT CURSOR_TYPE)
 10  is
 11      l_query long := 'select di.DEALER_NAME,
 12      di.DEALER_ADDRESS1, di.DEALER_ADDRESS2, di.DEALER_CITY,
 13      di.DEALER_STATE,di.DEALER_ZIP,   di.DEALER_PHONE, di.DEALER_FAX,
 14      di.DEALER_URL_LINK, di.brand1, di.brand2,
 15      di.brand3, zd.DISTANCE from dealer_information di, zip_distance zd  where
 16      dealer_zip = zd.ZIP_CODE_TO
 17      and distance <= :in_radius';
 18  begin
 19      if ( in_city is not null )
 20      then
 21          l_query := l_query || ' and di.dealer_city = sys_context( ''my_ctx'',''city'' )'; 22          dbms_session.set_context( 'my_ctx', 'city', in_city );
 23      end if;
 24      if ( in_state is not null )
 25      then
 26          l_query := l_query || ' and di.dealer_state = sys_context( ''my_ctx'',''state'' )';
 27          dbms_session.set_context( 'my_ctx', 'state', in_state );
 28      end if;
 29      if ( in_zip is not null )
 30      then
 31          l_query := l_query || ' and zip_code_from = sys_context( ''my_ctx'',''zip'' )';
 32          dbms_session.set_context( 'my_ctx', 'zip', in_zip );
 33      end if;
 34
 35      p(l_query);
 36      -- open oresult_set for l_query USING IN_RADIUS;
 37  end;
 38
 39
 40  end;
 41  /
 
Package body created.
 
ops$tkyte@ORA9IR2> show error
No errors.
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> variable x refcursor
ops$tkyte@ORA9IR2> exec my_pkg.get_search_results( 'city', 'state', 'zip', 0, :x )
select di.DEALER_NAME,
    di.DEALER_ADDRESS1, di.DEALER_ADDRESS2,
di.DEALER_CITY,
    di.DEALER_STATE,di.DEALER_ZIP,   di.DEALER_PHONE,
di.DEALER_FAX,
    di.DEALER_URL_LINK, di.brand1, di.brand2,
 
di.brand3, zd.DISTANCE from dealer_information d
i, zip_distance zd  where
    dealer_zip = zd.ZIP_CODE_TO
    and
distance <= :in_radius and di.dealer_city = sys_context( 'my_ctx','city'
) and di.dealer_state = sys_context( 'my_ctx','state' ) and
zip_code_from = sys_context( 'my_ctx','zip' )
 
PL/SQL procedure successfully completed.
 

 

privileges on using context

mary w, April 15, 2004 - 9:33 am UTC

ERROR at line 1:
ORA-01031: insufficient privileges
ORA-06512: at "SYS.DBMS_SESSION", line 58
ORA-06512: at "XMR.LOCATION_SEARCH_V1", line 29
ORA-06512: at line 1


my pacakge has all privileges and so does my procedure.  is there anything else that needs to happend here?

this is how i call my package:
SQL> variable x refcursor
SQL>  exec LOCATION_SEARCH_V1.get_search_results( 'city', 'state', 'zip', 0, :x );


thanks. 

Tom Kyte
April 15, 2004 - 9:43 am UTC

you showed everything but the create context...

Unless you did this:



ops$tkyte@ORA9IR2> create or replace context my_ctx using LOCATION_SEARCH_V1
  2  /
 
Context created.


it won't work for you -- you need to bind the context to the package itself.
 

Can she do this?

Vera, April 15, 2004 - 9:57 pm UTC

Tom,
I realize that your solutions are always the best, but whatever they say women are not as smart as men :)so please help me understand the difference between what you suggested and the following:

IF (in_city IS NOT NULL OR in_state IS NOT NULL OR in_zip IS NOT NULL)
THEN

OPEN oresult_set FOR

select di.DEALER_NAME,
di.DEALER_ADDRESS1, di.DEALER_ADDRESS2, di.DEALER_CITY,
di.DEALER_STATE,di.DEALER_ZIP, di.DEALER_PHONE, di.DEALER_FAX,
di.DEALER_URL_LINK, di.brand1, di.brand2,
di.brand3, zd.DISTANCE from dealer_information di, zip_distance zd
where
dealer_zip = zd.ZIP_CODE_TO
and distance <= in_radius
AND ( di.dealer_city=NVL(in_city,'-') OR di.dealer_state=NVL(in_state,'-') OR zip_code_from=NVL(in_zip,'-'));

END IF;
--I don't know what characters are stored in their
--database, but of course NVL should return characters
--that cannot be there. And OR can be replaced with UNION
--depending on which one is faster in their environment

Also I want to thank you for your help with one of my questions. Since I removed TRUNCATEs and COMMITs from loops and re-wrote everything related to loading and truncating "intermediate" tables two months ago, applications that took around 24 and 36 hours are now running 1.5 and 2 hours. I also used your advise to apply DBMS_APPLICATION_INFO to inform users on the profgess and it works great!
God bless you, Tom.

Tom Kyte
April 16, 2004 - 7:16 am UTC

(spare me on the women vs men ;) I'm not as 'right' as often at home!)

tell me if you think the optimal plans for:


where dealer_zip = zd.ZIP_CODE_TO
and distance <= in_radius

where dealer_zip = zd.ZIP_CODE_TO
and distance <= in_radius
AND di.dealer_city= :x;


where dealer_zip = zd.ZIP_CODE_TO
and distance <= in_radius
AND di.dealer_state = :x


where dealer_zip = zd.ZIP_CODE_TO
and distance <= in_radius
AND zip_code = :x


where dealer_zip = zd.ZIP_CODE_TO
and distance <= in_radius
AND di.dealer_city= :x;
AND di.dealer_state = :y

and so on, would be the same for each -- or might they be radically different.

this:

AND ( di.dealer_city=NVL(in_city,'-') OR di.dealer_state=NVL(in_state,'-') OR
zip_code_from=NVL(in_zip,'-'));

would preclude indexes pretty much.


When you have a situation where you are getting a bunch of columns and constraints against those columns -- dynamic sql to generate a bind friendly query in a standard fashion is going to give the optimizer the best chance.

I think I know the answer

Vera, April 16, 2004 - 12:20 am UTC

Tom,
Will the answer to my question be that OR or UNION are going to be slower than
"WHERE column_value=value_of_bind_variable"?

Tom Kyte
April 16, 2004 - 7:20 am UTC

the functions are the primary culprit here.

Dynamic Query

mary W, April 19, 2004 - 12:05 pm UTC

Thank you, Tom for all of your help so far. I got two questions:

1. Do I have to do' create or replace context LOC_SEARCH_CTX using LOCATION_SEARCH_V1;" everytime before i call my stored procedure so i can set those sessions?

i will be calling the procedure from a servlet using callable statement

2. What is the meaning of this error:
ERROR at line 1:
ORA-06550: line 1, column 7:
PLS-00201: identifier 'LOCATION_SEARCH_V1.GET_SEARCH_RESULTS' must be declared
ORA-06550: line 1, column 7:
PL/SQL: Statement ignored

resulted from: variable x refcursor
exec LOCATION_SEARCH_V1.get_search_results( '', '', 22206, 10, :x);

thanks

Tom Kyte
April 19, 2004 - 12:30 pm UTC

1) no, it is like creating a table, you do it once.

2) desc location_search_v1 in sqlplus. what do you see.

Dynamic Query

Mary W, April 19, 2004 - 12:44 pm UTC

Of course i was on the wrong server!

Everything seems to work ok now.  But I am not seeing results not even one row....

SQL> variable x refcursor
SQL> exec LOCATION_SEARCH_V1.get_search_results( '', '', 22206, 10, :x);
select di.DEALER_NAME,
     di.DEALER_ADDRESS1, di.DEALER_ADDRESS2,
di.DEALER_CITY,
   di.DEALER_STATE,di.DEALER_ZIP,   di.DEALER_PHONE,
di.DEALER_FAX,
   di.DEALER_URL_LINK, di.brand1, di.brand2,
      di.brand3,
zd.DISTANCE from dealer_information
di, zip_distance zd
where
      dealer_zip = zd.ZIP_CODE_TO
      and distance
<= :in_radius and zip_code_from = sys_context( 'LOC_SEARCH_CTX','zip' )

PL/SQL procedure successfully completed. 

Tom Kyte
April 19, 2004 - 3:03 pm UTC

well, if you are using my package:

 34
 35      p(l_query);
 36      -- open oresult_set for l_query USING IN_RADIUS;
 37  end;
 38

the open is commented out (i don't have your tables!)

if you uncommented that, then

SQL> print x

will show you what you got (or just set autoprint on in sqlplus and it'll print all output bind variables)
 

Works great!

Mary Wiest, April 19, 2004 - 3:10 pm UTC

Thank you so much, Tom!

I will be using bind variables all the time now!

--mw

Callable statement and bind variables

Mary W, April 19, 2004 - 3:26 pm UTC

One last question.

If i am calling a stored procedure from java using callable statement will the :x mess me up?

SQL="{call xmr.LOCATION_SEARCH_V1.get_search_results(?,?,?,?,?,:?)}";

Tom Kyte
April 19, 2004 - 7:28 pm UTC

I would think it would -- ? is how to bind. not sure what :? would do.

? is all you need.

A reader, April 27, 2004 - 9:17 pm UTC

Tom,

How can i track my cursor meaning, how may records the cursor has processed and how many more to go what is it doing other than using a counter in the fetch.

Thanks.

Sys_context

Oleg Oleander, May 05, 2004 - 4:54 am UTC

I have 2 querys that use sys_context for binding variables. The only textual difference is that they use different attribute names in the sys_context. Will the optimizer hard parse the second query after the first have been executed?

Tom Kyte
May 05, 2004 - 7:54 am UTC

yes, they are different queries.

a Trailing blank is enough to make two queries different.

Max, May 12, 2004 - 10:29 am UTC

Hi Tom,

I would like to know is it possible to know the record count of a cursor before opening it? If so, how?

Regrads

Max

Tom Kyte
May 12, 2004 - 6:53 pm UTC

no, not even oracle knowns how many rows it'll return until it actually returns it!


consider the implication of a simple:



select * from ten_billion_row_table;


what if Oracle "knew" how many rows that would return? That would imply Oracle ran the query. That would be painful. We execute the query as you fetch -- we don't pre-answer the query anywhere. (if you want a much more detailed discussion -- i did cover this in Effective Oracle by Design)

still hard parsing

Oleg Oleander, May 14, 2004 - 7:43 pm UTC

Dear Tom,

I have a rutine that executes a grouping SQL 16 times in execute immediate to get the results. The SQL is the same every time, it uses sys_context to bind variables. Than I run tkprof, and see this:

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 16 3.22 3.56 0 444 0 0
Execute 16 0.01 0.01 0 0 0 0
Fetch 16 4.04 5.43 241 5590 0 16
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 48 7.28 9.01 241 6034 0 16

Misses in library cache during parse: 16
Optimizer goal: CHOOSE
Parsing user id: 48 (recursive depth: 3)

Why is the query hard parsed for every single execution?
How can I get rid of those hard parses than?

Thank you for your time.
Oleg

Tom Kyte
May 15, 2004 - 12:29 pm UTC

gotta example for me?


declare
l_cnt number;
begin
for i in 1 .. 16
loop
execute immediate 'select count(*) from dual group by dummy'
into l_cnt;
end loop;
end;

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.01 0.00 0 3 0 1
Fetch 0 0.00 0.00 0 0 0 0
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 2 0.01 0.01 0 3 0 1

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 120

Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
SQL*Net message to client 1 0.00 0.00
SQL*Net message from client 1 0.00 0.00
********************************************************************************

select count(*)
from
dual group by dummy


call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 16 0.00 0.00 0 0 0 0
Execute 16 0.00 0.00 0 0 0 0
Fetch 16 0.00 0.00 0 48 0 16
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 48 0.00 0.00 0 48 0 16

Misses in library cache during parse: 1
Optimizer goal: CHOOSE
Parsing user id: 120 (recursive depth: 1)

Rows Row Source Operation
------- ---------------------------------------------------
1 SORT GROUP BY (cr=3 r=0 w=0 time=99 us)
1 TABLE ACCESS FULL DUAL (cr=3 r=0 w=0 time=45 us)

That is mine.

I think I found the reason

Oleg, May 17, 2004 - 5:03 pm UTC

Dear Tom,

The SQL statment in question uses a temporary table that is populated and ANALYZED for every execution. Behind this implementation is the following reason:
The temporary table stores 3 to 2000 rows as a result from a 3 table join and filtering conditions. The TMP table is then joined to a big table constaining couple of 100000 rows. The temp table has a 2 column unique index for the join, the bigger table has also the equivalent columns indexed. An inline view -instead of the temp table - could not use index so the join would be slower. Does it make any sense? (we are about to test these scenarios) pls comment. If it does than Can we leave the analyze statement out?
Thank you very much


Tom Kyte
May 18, 2004 - 7:35 am UTC

not understanding why an index view "could not be used", it would not preclude indexes or anything.

Oleg, May 18, 2004 - 8:12 am UTC

What is an "index view"? Am I missing a feature of the server?

The temp table is the result of a cartasian join of really tiny tables (containing access rights), and the two column index is not present only on the temp table. Thank you

Tom Kyte
May 18, 2004 - 3:01 pm UTC

sorry -- meant the INLINE view, don't see why that cannot be used with an index.

DBMS_SESSION.SET_CONTEXT parameter limit

dxl, May 24, 2004 - 10:57 am UTC

Tom

I have used the DBMS_SESSION.SET_CONTEXT method that you have described at the top of this question. Until now it has been working perfectly.

However since i am using a query which selects a long list of ids i have hit the limit of 256 characters in the set_context method.
The following script demonstates this:



drop table t1;
create table t1 (c1 number(10));

insert into t1 values (1);
insert into t1 values (2);
insert into t1 values (3);
insert into t1 values (4);
insert into t1 values (5);


select * from
t1 where 1=1
and c1 in (1, 2, 3)
or c1 in (4,5,6);

CREATE OR REPLACE TYPE tbl_Numbers AS TABLE OF NUMBER;
/



CREATE OR REPLACE FUNCTION str2tbl( p_str in varchar2 )

RETURN tbl_Numbers

AS

l_str long default p_str || ',';
l_n number;
l_data tbl_Numbers := tbl_Numbers();

BEGIN
LOOP
l_n := instr( l_str, ',' );
exit when (nvl(l_n,0) = 0);
l_data.extend;
l_data( l_data.count ) := ltrim(rtrim(substr(l_str,1,l_n-1)));
l_str := substr( l_str, l_n+1 );
END LOOP;

RETURN l_data;

END;

/



CREATE OR REPLACE PACKAGE PKG1 AS

TYPE C_Return_Cursor IS REF CURSOR;

procedure p1 ( P_String IN VARCHAR2 DEFAULT NULL,
P_Cur IN OUT C_Return_Cursor );

end pkg1;
/


CREATE OR REPLACE PACKAGE BODY PKG1 AS


procedure p1 ( P_String IN VARCHAR2 DEFAULT NULL,
P_Cur IN OUT C_Return_Cursor )

is

l_query varchar2(32000)
default 'SELECT c1 from t1 where 1=1 ';


begin



DBMS_SESSION.SET_CONTEXT( 'MY_CTX', 'STRING', P_String);
l_query := l_query ||' AND c1 IN ( SELECT *
FROM THE ( SELECT CAST( str2tbl( sys_context( ''MY_CTX'', ''STRING'' ) ) as tbl_Numbers ) from dual ) ) ';




open P_Cur for l_query ;




end p1;


end pkg1;
/


CREATE OR REPLACE CONTEXT MY_CTX USING PKG1;

set autoprint on
variable x refcursor;
exec PKG1.P1('40,141,142,143,144,145,146,147,148,150,151,153,154,155,156,158,159,160,161,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,199,200,201,202,203,204,205,206,207,208,209,210,211,213,264,216,217,218,219,231,252,254,255,257,258,259,260,261,263,214,1', :x);

PL/SQL procedure successfully completed.


C1
----------
1

So now if i add another id to this list of ids to select id 2 as well it fails:

15:30:14 OPT1@OP2>exec PKG1.P1('40,141,142,143,144,145,146,147,148,150,151,153,154,155,156,158,159,1
60,161,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,199,200,201,202,203,204,205,206,2
07,208,209,210,211,213,264,216,217,218,219,231,252,254,255,257,258,259,260,261,263,214,1,2', :x);

PL/SQL procedure successfully completed.


C1
----------
1

This time i use the same list as above but shorten it by a few characters (i chopped id 40 from the front of the list):

15:33:05 OPT1@OP2>exec PKG1.P1('141,142,143,144,145,146,147,148,150,151,153,154,155,156,158,159,160,
161,182,183,184,185,186,187,188,189,190,191,192,193,194,195,196,199,200,201,202,203,204,205,206,207,
208,209,210,211,213,264,216,217,218,219,231,252,254,255,257,258,259,260,261,263,214,1,2', :x);

PL/SQL procedure successfully completed.


C1
----------
1
2

So set_context only accepts the first 256 characters. How could i best get around this problem??

One way would be to use an OR in the select query and split the string up.
Would this mean i need an additional application context though? eg something like

DBMS_SESSION.SET_CONTEXT( 'MY_CTX', 'STRING', SUBSTR(P_String, 1, 256));
DBMS_SESSION.SET_CONTEXT( 'MY_CTX_2', 'STRING', SUBSTR(P_String, 257));

l_query := l_query ||' AND c1 IN ( SELECT *
FROM THE ( SELECT CAST( str2tbl( sys_context( ''MY_CTX'', ''STRING'' ) ) as tbl_Numbers ) from dual ) )

OR c1 IN SELECT *
FROM THE ( SELECT CAST( str2tbl( sys_context( ''MY_CTX_2'', ''STRING'' ) ) as tbl_Numbers ) from dual ) )';


Would this be the best way or can you think of any better method??

Thanks

Tom Kyte
May 24, 2004 - 11:17 am UTC

alternative -- instead of using str2tbl, put the values in the context space itself.



for i in 1 .. 99999
LOOP
l_n := instr( l_str, ',' );
exit when (nvl(l_n,0) = 0);
dbms_session.set_context( 'my_ctx', 'in_list_' || i,
ltrim(rtrim(substr(l_str,1,l_n-1)) );
l_str := substr( l_str, l_n+1 );
END LOOP;

and then use

in ( select to_number(value) from session_context where namespace = 'MY_CTX' and attribute like 'IN\_LIST\_%' escape '\' )

as you "in"


thanks

dxl, May 24, 2004 - 11:56 am UTC

Thanks, that was very useful.
I understand everything you did except the last bit:

in ( select to_number(value) from session_context where namespace = 'MY_CTX'
and attribute like 'IN\_LIST\_%' escape '\' )


why is the escape \ necessary in the when using the like function? wouldn't

like 'IN_LIST_%'

work too?

So is that what the call to sys_context is doing then? ie selecting from the session_Context table??
Does the session_context table only get cleared down after the session is terminated?

Tom Kyte
May 24, 2004 - 1:01 pm UTC

"_" is a wildcard as well. it would "work", but it would match inxlisty as well as in_list_


sys_context is accessing the same information presented in this view.

session_context contains the set of values you have set in your session, they stay there until the corresponding sys_context retrievable values go away.




scope of application contect

A reader, June 14, 2004 - 3:20 pm UTC

Is the scope application wise or within the procedure?

eg:
9 dbms_session.set_context( 'MY_CTX', 'ENAME', upper(p_ename) );
10 l_query := l_query || ' and ename like sys_context( ''MY_CTX'', ''ENAME'' ) ';


suppose the procedure is executed with p_ename value as "ABC" and line 9 is completed.
another user may run the same procedure with a different value like " XYZ" and line 9 is completed.
now when line 10 is being executed , for the first user, will the value be "XYZ" or "ABC"?

Hope you understood this. if not let me know so that i can explain clearly.

Thanks,


Tom Kyte
June 15, 2004 - 8:02 am UTC

either

a) session -- your SESSION sees the values
b) as long as you like -- global application contexts can persist over/across sessions.

by default, the context is scoped at the session.


since each user would have their own session -- or in a connection pool use the session "one after the other", your concern is not a problem. they will not see eachothers context values.

dynamically reference value from cursor

A reader, June 16, 2004 - 9:51 am UTC

Given the following scenario:

SQL> set serveroutput on
SQL> drop table emp;

Table dropped.

SQL> 
SQL> drop table t;

Table dropped.

SQL> 
SQL> create table emp
  2  ( first_name varchar2(30),
  3    last_name varchar2(30)
  4  );

Table created.

SQL> 
SQL> insert into emp
  2  values('JOHN','SMITH');

1 row created.

SQL> 
SQL> insert into emp
  2  values('JANE','JONES');

1 row created.

SQL> 
SQL> create table t
  2  ( 
  3    name varchar2(10),
  4    cursor_column varchar2(30)
  5  );

Table created.

SQL> 
SQL> insert into t
  2  values ('TEST1','emp_cur.last_name');

1 row created.

SQL> 
SQL> insert into t
  2  values ('TEST2','emp_cur.first_name');

1 row created.

SQL> 
SQL> commit;

Commit complete.

SQL> 
SQL> begin
  2   for emp_cur in (select * from emp)
  3   loop
  4     for t_cur in (select * from t where name='TEST1')
  5     loop
  6     dbms_output.put_line(t_cur.cursor_column);
  7     dbms_output.put_line(' I really wanted to output '||emp_cur.last_name||' but I dont know how
 to dynamically reference the cursur value');
  8     end loop;
  9   end loop;
 10  end;
 11  /
emp_cur.last_name
I really wanted to output SMITH but I dont know how to dynamically reference the
cursur value
emp_cur.last_name
I really wanted to output JONES but I dont know how to dynamically reference the
cursur value

PL/SQL procedure successfully completed.

SQL> 
SQL> begin
  2   for emp_cur in (select * from emp)
  3   loop
  4     for t_cur in (select * from t where name='TEST2')
  5     loop
  6     dbms_output.put_line(t_cur.cursor_column);
  7     dbms_output.put_line(' I really wanted to output '||emp_cur.first_name||' but I dont know ho
w to dynamically reference the cursur value');
  8     end loop;
  9   end loop;
 10  end;
 11  /
emp_cur.first_name
I really wanted to output JOHN but I dont know how to dynamically reference the
cursur value
emp_cur.first_name
I really wanted to output JANE but I dont know how to dynamically reference the
cursur value

PL/SQL procedure successfully completed.

SQL> 
SQL> 


I want to be get a value from a cursor dynamically. Hopefully my question makes sense. 

Tom Kyte
June 16, 2004 - 12:59 pm UTC

ops$tkyte@ORA9IR2> select decode( t.cursor_column, 'first_name', emp.first_name, 'last_name', emp.last_name )
  2    from t, emp
  3   where t.name = 'TEST1'
  4  /
 
DECODE(T.CURSOR_COLUMN,'FIRST_
------------------------------
SMITH
JONES
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> select decode( t.cursor_column, 'first_name', emp.first_name, 'last_name', emp.last_name )
  2    from t, emp
  3   where t.name = 'TEST2'
  4  /
 
DECODE(T.CURSOR_COLUMN,'FIRST_
------------------------------
JOHN
JANE
 



let the database join.
never code loops like you did:

  for x in ( select * from t1 )
  loop
     for y in ( select * from t2 where t2.xxx = x.xxx )
     loop

never do that, JUST JOIN. 

Try again

A reader, June 16, 2004 - 1:53 pm UTC

You said:
>let the database join.
>never code loops like you did:

> for x in ( select * from t1 )
> loop
> for y in ( select * from t2 where t2.xxx = x.xxx )
> loop

>never do that, JUST JOIN.

I would never do that, I would just join. However, I was just trying to give you an easy example that illustrated my problem. Your decode solution would not work because at run time I do not know the values that I would be comparing on. They are coming from table T ( the second cursor). The second cursor returns from table T, the column name from the first cursor that I want to get the value from.

Tom Kyte
June 16, 2004 - 3:38 pm UTC

then you will be using dynamic sql. you cannot dynamically refer to the values (and you did do that which you said you would not do).

beware "overly generic" code. it always seems soooo cool at design time. rarely ever again after that.





How to just set hints dynamically in a cursor?

Arn, June 17, 2004 - 3:13 am UTC

I hope this is relevant...

I am taking a similar approach to that outlined originally here to solve our problem.

We are converting an existing program into a new cursor. The existing program, for various reasons, used 6 cursors that were essentially identical, but varied in the hints they used depending on the parameters passed in. (The table isn't analysed, and simply analysing the table and leting the CBO do its thing is not an option.)

I have started using Native Dynamic SQL to allow me to set the hint at runtime. However, this is complicating and reducing the readability of the rest of the SQL due to the positional parameters. Everything bar the hint can be written statically, and is much more readable that way.

Is there a simpler way to set a hint for a cursor at runtime? So far dynamic SQL seems to be the only way.

Thanx for any advice.

Tom Kyte
June 17, 2004 - 9:58 am UTC

i'd rethink my options. really. most of the time "not an option" is "an option" (or an opportunity)......


if you want to change the text of the query at runtime, dynamic sql is your only alternative (besides letting the software do what the software does for you...)

Implicit Conversion Problem?

Mike Burford, June 29, 2004 - 5:11 pm UTC

Hello Tom,
We use a different approach to REF CURSORS with dynamic
where clauses. We are populating a PLSQL table with values and then binding like this:
IF (tBindVars.COUNT = 2)
THEN
OPEN l_cursor FOR l_query_pl USING tBindVars(1), tBindVars(2);
ELSIF (tBindVars.COUNT = 1) THEN ...

We discovered a performance problem with one query involving a date. I found that if I used a true date datatype as the bind variable as opposed to the to_date(varchar2) from the PLSQL table, the query plan was different and very fast. The SYS_CONTEXT test I ran mimicked the slower to_date(varchar2) method.

I put together a test procedure with your SYS_CONTEXT method, our PLSQL Table method, and the "Dummy Where" clause method mentioned in this article (so I could pass a date datatype). The output below shows the different execution plans, resources used, and response times. The PLSQL method shows dty=1 whereas the Dummy method shows dty=12. The SYS_CONTEXT method doesn't expose any bind information. Could it be that implicit conversion is still happening in the PLSQL method and SYS_CONTEXT method and this is causing the optimizer to generate different access paths? Do you have any other thoughts on what might be happening and how to get around it?

***SYS_CONTEXT TRACE:
PARSING IN CURSOR #2 len=521 dep=1 uid=42 oct=3 lid=42 tim=5353026057216 hv=3250717028 ad='7df3f68'
PARSE #2:c=16667,e=16384,p=0,cr=2,cu=0,mis=1,r=0,dep=1,og=4,tim=5353026057216
BINDS #2:
EXEC #2:...

***SYS_CONTEXT TKPROF:
select distinct cas_caseid, cas_id, d.dispatch_status,
cas_name, cas_adddate, cas_queueassn,
first_value(notes) over (partition by unotes_bcs.addid
order by dateofca,timeofca,note_grp asc) notes
from cases cs, service_dispatch d, unotes_bcs
where 1 = 1
and cas_adddate <= to_date(sys_context('MY_CTX','CAS_ADDDATE'),'yyyymmddhh24miss')
and cas_caseid = d.DISPATCH_NUMBER and addid=cas_caseid and recordty = 'IA' order by cas_adddate desc

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.01 0.01 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 56 5.73 15.35 15871 23009 0 55
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 58 5.75 15.37 15871 23009 0 55

Rows Row Source Operation
------- ---------------------------------------------------
55 SORT UNIQUE
164 WINDOW SORT
164 TABLE ACCESS BY INDEX ROWID UNOTES_BCS
221 NESTED LOOPS
56 HASH JOIN
361 TABLE ACCESS FULL SERVICE_DISPATCH
353765 TABLE ACCESS BY INDEX ROWID CASES
353765 INDEX RANGE SCAN CASES_N14
164 INDEX RANGE SCAN UNOTES_BCS_N1


***PLSQL TABLE TRACE:
PARSING IN CURSOR #2 len=468 dep=1 uid=42 oct=3 lid=42 tim=5353041426432 hv=11255473 ad='81b27e0'
PARSE #2:c=0,e=1024,p=0,cr=0,cu=0,mis=0,r=0,dep=1,og=4,tim=5353041426432
BINDS #2:
bind 0: dty=1 mxl=32(09) mal=00 scl=00 pre=00 oacflg=13 oacfl2=1 size=32 offset=0
bfp=1403ec118 bln=32 avl=09 flg=05
value="01-JUN-04"
EXEC #2:...

***PLSQL TABLE TKPROF:
select distinct cas_caseid, cas_id, d.dispatch_status,
cas_name, cas_adddate, cas_queueassn,
first_value(notes) over (partition by unotes_bcs.addid
order by dateofca,timeofca,note_grp asc) notes
from cases cs, service_dispatch d, unotes_bcs
where 1 = 1 and cas_adddate <= to_date(:EndDate)
and cas_caseid = d.DISPATCH_NUMBER and addid=cas_caseid and recordty = 'IA' order by cas_adddate desc

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 56 4.21 14.15 15864 23009 0 55
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 58 4.21 14.15 15864 23009 0 55

Rows Row Source Operation
------- ---------------------------------------------------
55 SORT UNIQUE
164 WINDOW SORT
164 TABLE ACCESS BY INDEX ROWID UNOTES_BCS
221 NESTED LOOPS
56 HASH JOIN
361 TABLE ACCESS FULL SERVICE_DISPATCH
353765 TABLE ACCESS BY INDEX ROWID CASES
353765 INDEX RANGE SCAN CASES_N14
164 INDEX RANGE SCAN UNOTES_BCS_N1


***DUMMY WHERE TRACE:
PARSING IN CURSOR #2 len=493 dep=1 uid=42 oct=3 lid=42 tim=5353055599616 hv=3452234128 ad='7a986f0'
END OF STMT
PARSE #2:c=0,e=1024,p=0,cr=0,cu=0,mis=0,r=0,dep=1,og=4,tim=5353055599616
BINDS #2:
bind 0: dty=1 mxl=32(00) mal=00 scl=00 pre=00 oacflg=13 oacfl2=1 size=40 offset=0
bfp=1403ec118 bln=32 avl=00 flg=05
bind 1: dty=12 mxl=07(07) mal=00 scl=00 pre=00 oacflg=13 oacfl2=1 size=0 offset=32
bfp=1403ec138 bln=07 avl=07 flg=01
value="6/1/2004 0:0:0"
EXEC #2:...

***DUMMY WHERE TKPROF:
select distinct cas_caseid, cas_id, d.dispatch_status,
cas_name, cas_adddate, cas_queueassn,
first_value(notes) over (partition by unotes_bcs.addid
order by dateofca,timeofca,note_grp asc) notes
from cases cs, service_dispatch d, unotes_bcs
order by dateofca,timeofca,note_grp asc) notes
from cases cs, service_dispatch d, unotes_bcs
where 1 = 1 and 1 = DECODE(:Account,NULL,1,1) and cas_adddate <= :EndDate
and cas_caseid = d.DISPATCH_NUMBER and addid=cas_caseid and recordty = 'IA' order by cas_adddate desc

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 1 0.00 0.00 0 0 0 0
Execute 1 0.00 0.00 0 0 0 0
Fetch 56 0.01 0.06 61 1277 0 55
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 58 0.01 0.07 61 1277 0 55

Rows Row Source Operation
------- ---------------------------------------------------
55 SORT UNIQUE
164 WINDOW SORT
164 FILTER
164 TABLE ACCESS BY INDEX ROWID UNOTES_BCS
221 NESTED LOOPS
56 NESTED LOOPS
361 TABLE ACCESS FULL SERVICE_DISPATCH
56 TABLE ACCESS BY INDEX ROWID CASES
361 INDEX UNIQUE SCAN CASES_PK
164 INDEX RANGE SCAN UNOTES_BCS_N1


Tom Kyte
June 29, 2004 - 6:57 pm UTC


be interesting to compare the autotrace traceonly explain with the tkprofs -- to see why the optimizer chose the wrong index. this is CBO right?

it is not the datatypes.

you are comparing

where x = to_date.... -- a date to a date

vs

where x = :bind_variable that is a date -- a date to a date

that's not it.




Baffled by optimizer

Mike Burford, June 30, 2004 - 2:42 pm UTC

Yes, this is CBO on 9.2.0.5. I've included the autotrace output below. It clearly shows the cost of the fast plan is higher than the cost of the slow plan, but I don't know how to read how it got there.

Another intesesting finding is that if I put the bind variable (date datatype) into a function like TRUNC or TO_DATE, the plan reverts to the slow plan.

Thanks for your time Tom,
Mike

SQL> @mb2
PL/SQL procedure successfully completed.
55 rows selected.
Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=9984 Card=130 Bytes= 20150)
   1    0   SORT (UNIQUE) (Cost=9977 Card=130 Bytes=20150)
   2    1     WINDOW (SORT) (Cost=9984 Card=130 Bytes=20150)
   3    2       TABLE ACCESS (BY INDEX ROWID) OF 'UNOTES_BCS' (Cost=27 Card=1 Bytes=74)
   4    3         NESTED LOOPS (Cost=9963 Card=130 Bytes=20150)
   5    4           HASH JOIN (Cost=216 Card=361 Bytes=29241)
   6    5             TABLE ACCESS (FULL) OF 'SERVICE_DISPATCH' (Cost=5 Card=361 Bytes=6137)
   7    5             TABLE ACCESS (BY INDEX ROWID) OF 'CASES' (Cost=210 Card=17710 Bytes=1133440)
   8    7               INDEX (RANGE SCAN) OF 'CASES_N14' (NON-UNIQUE) (Cost=14 Card=1)
   9    4           INDEX (RANGE SCAN) OF 'UNOTES_BCS_N1' (NON-UNIQUE) (Cost=2 Card=1)
Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
      23012  consistent gets
      17064  physical reads
          0  redo size
       4127  bytes sent via SQL*Net to client
        688  bytes received via SQL*Net from client
          5  SQL*Net roundtrips to/from client
          2  sorts (memory)
          0  sorts (disk)
         55  rows processed


SQL> @mb2
PL/SQL procedure successfully completed.
55 rows selected.
Execution Plan
----------------------------------------------------------
   0      SELECT STATEMENT Optimizer=CHOOSE (Cost=10495 Card=130 Bytes=20150)
   1    0   SORT (UNIQUE) (Cost=10488 Card=130 Bytes=20150)
   2    1     WINDOW (SORT) (Cost=10495 Card=130 Bytes=20150)
   3    2       TABLE ACCESS (BY INDEX ROWID) OF 'UNOTES_BCS' (Cost=27 Card=1 Bytes=74)
   4    3         NESTED LOOPS (Cost=10474 Card=130 Bytes=20150)
   5    4           NESTED LOOPS (Cost=727 Card=361 Bytes=29241)
   6    5             TABLE ACCESS (FULL) OF 'SERVICE_DISPATCH' (Cost= 5 Card=361 Bytes=6137)
   7    5             TABLE ACCESS (BY INDEX ROWID) OF 'CASES' (Cost=2 Card=1 Bytes=64)
   8    7               INDEX (UNIQUE SCAN) OF 'CASES_PK' (UNIQUE) (Cost=1 Card=1)
   9    4           INDEX (RANGE SCAN) OF 'UNOTES_BCS_N1' (NON-UNIQUE) (Cost=2 Card=1)
Statistics
----------------------------------------------------------
          0  recursive calls
          0  db block gets
       1282  consistent gets
         39  physical reads
          0  redo size
       4127  bytes sent via SQL*Net to client
        688  bytes received via SQL*Net from client
          5  SQL*Net roundtrips to/from client
          2  sorts (memory)
          0  sorts (disk)
         55  rows processed 

Tom Kyte
June 30, 2004 - 3:06 pm UTC

i've no idea what I'm looking at here....

Baffled by optimizer

Mike Burford, June 30, 2004 - 4:53 pm UTC

I was trying to supply what you suggested above:

"Followup:

be interesting to compare the autotrace traceonly explain with the tkprofs -- to
see why the optimizer chose the wrong index. this is CBO right?"

I pasted the output from autotrace traceonly explain on the two statements that were in my post above that included the tkprof output.

I must be misinterpreting what you were suggesting. What should I be supplying?

Thanks,
Mike




Tom Kyte
June 30, 2004 - 8:05 pm UTC

i didn't put the two together (didn't "look up").

the lack of query text didn't clue me in that this was a follow on.



so, the indexes, what are they on exactly?

How can we make the Sys_Context Available to every one

Qaisar, July 05, 2004 - 12:13 pm UTC

Hi Tom,
It's so nice but I have a question, How can we use the context created in a schema while the procedure is being used by different users. We have only one schema under the name PDMAN and every user is given the execute priviliges on the packages through roles. When I execute the package, I get the error Insufficient Privileges. I'm able to execute the packaged procedures if I comment out the sys_context clause.
Please help.


Tom Kyte
July 05, 2004 - 1:40 pm UTC

how did you create the context? if you:

create context your_context_name using that_package_name;

there should not be a problem -- if you have one, show the entire method to reproduce it -- all necessary commands one would need to type in.

Error getting in SQL Clause

Qaisar, July 05, 2004 - 6:34 pm UTC

I always get an error "ORA-28106: input value for argument #2 is not valid" when I'm testing the procedure that builds the dynamic sql by using context method for one parameter. All the other parameters are fine, this is only one parameter that throws an error, Any Idea?

Here is the Context statement that I created under particular schema "Create Context CTX_EDUC_PGM Using FMS_EDUCATION_PROGRAM_Q" but the others users get error when executing the procedure FMS_EDUCATION_PROGRAM_Q.FMS_EDUCATION_PROGRAM, even the users do have execute privileges and they can still execute if I comment out the context statement in building the dynamic sql.

Please help?

Tom Kyte
July 05, 2004 - 8:27 pm UTC

you *must* supply a concise, yet 100% complete test case to demonstrate your issue.

just like I do -- starting with CREATE USER if that is relevant to the problem.

Triggers & Procedures

venkat, July 06, 2004 - 9:00 am UTC

Why a trigger is allowed to have the same name as the table??
Can two different schema objects have the same name??


Tom Kyte
July 06, 2004 - 9:05 am UTC

because the trigger namespace is the trigger namespace.

Just like a constraint can have the same name as an index.

names in the trigger namespace = unique;
names in the constraint namespace = unique;
other names are unique in the more "global" namespace.


remember also that a user scott can create a table or package scott (not recommend!)

Procedure in Error

Qaisar, July 06, 2004 - 12:28 pm UTC

create or replace context MY_CTX using pk_emp;
Create table employee as select * from emp;
alter table employee add(employee_soundex_indicate_on Varchar2(1));
Update employee set employee_soundex_indicate_on = 'Y';

create or replace package pk_emp
is
Type search_rec is RECORD
(pempno emp.empno%type,
pename emp.ename%TYPE,
pjob emp.job%TYPE,
phiredate emp.hiredate%TYPE,
psal emp.sal%TYPE);
--Type search_cur is REF CURSOR return search_rec ;
Type search_cur is REF CURSOR; -- return search_rec ;

Procedure p_search (resultset IN out search_cur,
p_empno IN number,
p_name Varchar2,
p_employee_soundex_indicate_on IN Varchar2);
end pk_emp;
/

create or replace package body pk_emp
is
Procedure p_search (resultset IN out search_cur,
p_empno IN number,
p_name Varchar2,
p_employee_soundex_indicate_on IN Varchar2 )
is
lv_sql Varchar2(2000);
begin
lv_sql :=
'Select emp.empno,
emp.ename,
emp.job,
emp.hiredate,
emp.sal
From Employee emp
Where 1 = 1 ';
If p_empno is not null Then
dbms_session.set_context( 'MY_CTX', 'emp.empno', p_empno);
lv_sql := lv_sql||' and emp.empno = sys_context( ''MY_CTX'', ''emp.empno'' ) ';
end if;

If p_name is not null Then
dbms_session.set_context( 'MY_CTX', 'emp.ename', p_name);
lv_sql := lv_sql||' and emp.ename = sys_context( ''MY_CTX'', ''emp.Ename'' ) ';
end if;

If p_employee_soundex_indicate_on is not null Then
dbms_session.set_context( 'MY_CTX', 'emp.employee_soundex_indicate_on', p_employee_soundex_indicate_on);
lv_sql := lv_sql||' and emp.employee_soundex_indicate_on = sys_context( ''MY_CTX'', ''emp.employee_soundex_indicate_on'' ) ';
end if;

DBMS_OUTPUT.PUT_LINE(LV_SQL);
Open resultset for lv_sql;
End p_search;

End pk_emp;
/

If you execute this with the parameter p_employee_soundex_indicate_on as Y, You get the error "ORA-28106: input value for argument #2 is not valid"

Tom Kyte
July 06, 2004 - 2:14 pm UTC

the variable name needs to be 30 characters or less.  it must be a valid identifier.  suggest you drop the emp. in the context, period.

ops$tkyte@ORA9IR2> create or replace package body pk_emp
  2  is
  3  Procedure p_search (resultset       IN out search_cur,
  4              p_empno IN number,
  5              p_name  Varchar2,
  6              p_employee_soundex_indicate_on IN Varchar2 )
  7  is
  8      lv_sql    Varchar2(2000);
  9  begin
 10      lv_sql :=
 11      'Select emp.empno,
 12          emp.ename,
 13          emp.job,
 14          emp.hiredate,
 15          emp.sal
 16      From    Employee emp
 17      Where 1 = 1 ';
 18      If p_empno is not null Then
 19          dbms_session.set_context( 'MY_CTX', 'empno', p_empno);
 20          lv_sql := lv_sql||' and emp.empno = sys_context( ''MY_CTX'', ''empno'' ) ';
 21      end if;
 22
 23      If p_name is not null Then
 24          dbms_session.set_context( 'MY_CTX', 'emp.ename', p_name);
 25          lv_sql := lv_sql||' and emp.ename = sys_context( ''MY_CTX'', ''Ename'' ) ';
 26      end if;
 27
 28      If p_employee_soundex_indicate_on is not null Then
 29          dbms_session.set_context( 'MY_CTX', 'employee_soundex_indicate_on', p_employee_soundex_indicate_on);
 30          lv_sql := lv_sql||' and emp.employee_soundex_indicate_on = sys_context( ''MY_CTX'', ''employee_soundex_indicate_on'' ) ';
 31      end if;
 32
 33      Open resultset for lv_sql;
 34  End p_search;
 35
 36  End pk_emp;
 37  /
 
Package body created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> variable x refcursor
ops$tkyte@ORA9IR2> exec pk_emp.p_search( :x, null, 'SMITH', 'Y' )
 
PL/SQL procedure successfully completed.
 

The Problem is Occuring in 8i

Qaisar, July 06, 2004 - 5:21 pm UTC

Hi Tom,

You are executing this on 9i, I have 8i and getting the error.

Tom Kyte
July 06, 2004 - 7:51 pm UTC

I corrected your code -- please reread my comment.

Your code as written did not run on 9i either.

the second argument to set_context must be a valid 30 character identifier, yours was not.

What if I have to include an alias

Maq, July 06, 2004 - 5:26 pm UTC

Hi Tom,

You said the variable length not to exceed 30. In this case the Column name is "employee_soundex_indicate_on" and length is 27, Let's suppose I still have to use emp.column_name in multi table join, Is there any way to handle this. Column length is not even 30 but with the alias it could exceed 30.

Tom Kyte
July 06, 2004 - 7:53 pm UTC

it is the set_context name that is limited to 30 characters.

there are no issues here at all -- not sure what you are concerned about.

You have a 30 character namespace "MY_CTX"

it can have a large set of values (think 26^30 number of values at the very least)


use "where emp.this_is_a_very_long_col_name = sys_context( 'my_ctx', 'x' )"

for example. It need not be named after the entire name.

Using a search form

A reader, July 12, 2004 - 1:36 pm UTC

I have a query like

select ...
from table
where 1=1
and field1=?
and field2=?
and field3=?
and ....

There are a total of 8 search fields. Some are varchar2, some are numeric, some are date (in which case it actually a date range i.e. date_field between d1 and d2)

i.e. a table (view actually) that has a "search form" on top of it for users to search based on diffent criteria. Your typical search form.

So, as with any search form, any field that the user enters a value for has to be ANDed into the query.

If I use dynamic SQL using the sys_context approach you demonstrate above, I would end up with (potentially) a factorial (or some high combinatorial number) based on 8 distinct SQLs (even if I use bind variables for each of the searchable fields)

Yes, if fields 1,3,5 are searched on most often, I will only have the SQL with these 3 fields in the WHERE clause in my shared pool.

But still, isnt there a way to just use 1 SQL statement, or at least minimize the distinct SQLs generated to do this?

Thanks

Tom Kyte
July 12, 2004 - 9:00 pm UTC

you want to minimize the number of unique statements -- taking things that don't use binds and binding them.

but you also want to get the best plan possible. a single query -- a single plan. no indexes.


I would use dynamic sql, you'll find that there will be a finite combo of columns people actually use.

Thanks a bunch!

Jamie, July 13, 2004 - 1:00 pm UTC

This was a fantastic article. I was easy to follow and helped my project out enormously. Thanks again!

question about using context

James Su, July 14, 2004 - 5:21 pm UTC

hi Tom,

I tried to use context:

SQL> create or replace context CTX_TEST using SP_TEST;

Context created.

SQL>
SQL> CREATE OR REPLACE PROCEDURE SP_TEST (p_value in number)
  2  as
  3  begin
  4     dbms_session.set_context('CTX_TEST', 'TEST', to_char(p_value));
  5  end;
  6  /

Procedure created.

SQL>
SQL> EXEC SP_TEST(10000);

PL/SQL procedure successfully completed.

SQL>
SQL> select to_number(sys_context('CTX_TEST','TEST')) from dual;

TO_NUMBER(SYS_CONTEXT('CTX_TEST','TEST'))
-----------------------------------------
                                    10000

SQL>
SQL> select CUST_ID from CUSTOMER where CUST_ID = to_number(sys_context('CTX_TEST','TEST'));

no rows selected

SQL> select CUST_ID from CUSTOMER where CUST_ID = 10000;

   CUST_ID
----------
     10000

You see, the row does exist, but I can't select it. 

Believe it or not, it does not work on this server(9.2.0.4.0), but works fine on another server (9.2.0.1.0) and I don't know why. 

Tom Kyte
July 15, 2004 - 11:47 am UTC

i'd need a reproducible example -- start from scratch on 9204, with a create table/insert into etc -- do everything you need to do to reproduce the issue

(compare the plans from all 4 cases as well -- are they the same or different)

about my last post

James Su, July 15, 2004 - 10:30 am UTC

hi Tom,

"CUSTOMER" from the example I showed in my last post is a synonym for a remote table. I tested on a local table and it worked.

Now I have to try another approach, to use package values instead of context.

Variable in Cursor

A reader, July 29, 2004 - 2:10 pm UTC

Hi Tom,

I have a procedure below,

--------------

PROCEDURE create_lookup_mviews IS

remote_dbname VARCHAR2(30);

cursor c1 is select table_name
from user_tables@
where table_name not like '%$%';

BEGIN

select db_link into remote_dbname from dba_db_links where owner='PUBLIC';

for c1_rec in c1 loop

if c1_rec.table_name='SHOP' then
dbms_output.put_line('CREATE MATERIALIZED VIEW '||c1_rec.table_name||' REFRESH FAST WITH PRIMARY KEY FOR UPDATE AS SELECT * FROM '||c1_rec.table_name||'@' || remote_dbname);


end if;

end loop;

END create_lookup_mviews;

--------------------

How do I put the dblink after the @ in the cursor c1 like I did inside the Begin part? How do I put another select statement after the @

Thanks!

Tom Kyte
July 29, 2004 - 2:20 pm UTC

you cannot -- you have to use dynamic sql

procedure...
is

type rc is ref cursor;
c1 rc;
begin
open c1 for 'select ..... @' || remote_dbname;
loop
fetch c1 into ..
exit when c1%notfound;
.....

end loop;
close c1;
end;


Return a weak ref cursor with datatypes

Doug, August 11, 2004 - 4:32 pm UTC

Since the only way I can use NDS is with a weak REF CURSOR. I was wondering what the best way would be to RETURN the result set as an OUT keeping the datatypes bound. Basically I need to know that "hiredate" is a DATE and "salary" is a NUMBER. Would the addition of a fetch/insert into global temp table with a separate cursor selecting from that be the solution. I am looking at the method you outlined to handle parameters passed from a search screen, the only problem is it appears the data types on the return wont be known and another level of coding will need to be added. Someone suggested that a possible solution would be to handle the parameters being passed from the search engine like a crystal report using a strong REF CURSOR...

I dont see this below as a valuble solution, if there are parameters that are not passed why add it to the WHERE clause and compare a wild.

WHERE column1 LIKE '%'
column2 LIKE '%param2%'
column3 LIKE '%param3%'
column4 LIKE '%'

what are your suggestions

Tom Kyte
August 12, 2004 - 8:27 am UTC

what is the client? they all should be able to describe the result set making weak ref cursors workable.

else, you won't be using NDS.

ORA 28106

dxl, August 12, 2004 - 6:16 am UTC

Tom

I am getting some strange behaviour when using application contexts. (db 8.1.7.4)
When i execute my package from a fresh session it will work the first time as expected then fail the next time
with an error

ORA-28106: input value for argument #1 is not valid



My package is:




CREATE OR REPLACE CONTEXT OPH_CTX USING PKG_OPH_GOS;


CREATE OR REPLACE PACKAGE PKG_OPH_GOS AS

TYPE C_Return_Cursor IS REF CURSOR;

PROCEDURE P_Get_Voucher ( P_Org_String IN VARCHAR2 DEFAULT NULL,
P_Cycle_String IN VARCHAR2 DEFAULT NULL,
P_Pract_String IN VARCHAR2 DEFAULT NULL,
P_Table_FLAG IN VARCHAR2,
P_Order IN VARCHAR2,
P_Cur IN OUT C_Return_Cursor );

END PKG_OPH_GOS;
/


CREATE OR REPLACE PACKAGE BODY PKG_OPH_GOS AS



PROCEDURE P_Get_Voucher ( P_Org_String IN VARCHAR2 DEFAULT NULL,
P_Cycle_String IN VARCHAR2,
P_Pract_String IN VARCHAR2 DEFAULT NULL,
P_Table_FLAG IN VARCHAR2,
P_Order IN VARCHAR2,
P_Cur IN OUT C_Return_Cursor )


IS

V_Org_String VARCHAR2(32000);
V_Cycle_String VARCHAR2(32000);
V_Pract_String VARCHAR2(32000);
l_n NUMBER(38);
l_query varchar2(32000);

V_Table VARCHAR2(10);
V_Order VARCHAR2(1000);


BEGIN

IF ( P_Table_FLAG = 'Y' ) THEN

V_Table := 'PAID_CLAIM';

ELSE V_Table := 'CLAIM';

END IF;


l_query := '
SELECT c.PAYMENT_ORG_CODE
FROM ' || V_Table || ' c,
ORGANISATION org
WHERE c.PAYMENT_ORG_ID = org.ORG_ID
and c.payment_org_code = ''QQQ''';

For rec_Cur IN (SELECT Namespace,
Attribute
FROM Session_Context
WHERE Namespace = 'OPH_CTX'
AND Attribute LIKE 'CYCLE\_IN\_LIST\_%' escape '\' ) LOOP

dbms_output.put_line('rec_Cur.Namespace = '|| rec_Cur.Namespace);
dbms_output.put_line('rec_Cur.Attribute = '|| rec_Cur.Attribute);

DBMS_SESSION.SET_CONTEXT( rec_Cur.Namespace, rec_Cur.Attribute, null); -- <--- ***** THS IS WHERE IT FALLS OVER *******


END LOOP;

V_Cycle_String := P_Cycle_String;


FOR i IN 1 .. 99999 LOOP
l_n := INSTR( V_Cycle_String, ',' );
EXIT WHEN (NVL(l_n, 0) = 0 AND length(V_Cycle_String) IS NULL );

IF l_n = 0 THEN
DBMS_SESSION.SET_CONTEXT( 'OPH_CTX', 'cycle_in_list_' || i, LTRIM(RTRIM(SUBSTR( V_Cycle_String, 1)) ));
V_Cycle_String := NULL;
ELSE
DBMS_SESSION.SET_CONTEXT( 'OPH_CTX', 'cycle_in_list_' || i, LTRIM(RTRIM(SUBSTR( V_Cycle_String, 1, l_n-1)) ));
V_Cycle_String := SUBSTR( V_Cycle_String, l_n+1 );
END IF;


END LOOP;


l_query := l_query ||' AND c.PAYMENT_CYCLE_ID IN ( SELECT TO_NUMBER(Value)
FROM Session_Context
WHERE Namespace = ''OPH_CTX''
AND Attribute LIKE ''CYCLE\_IN\_LIST\_%'' escape ''\'' )';



open P_Cur for l_query ;



END P_Get_Voucher;


END PKG_OPH_GOS;
/














It works the first time when it doesn't have to reset the session contexts but fails on the second run when session contexts exist.
I have looked at the first argument of the line where it falls over

DBMS_SESSION.SET_CONTEXT( rec_Cur.Namespace, rec_Cur.Attribute, null);


and the rec_Cur.Namespace evaluates to 'OPH_CTX' as you can see in the pasted sql text below :









SQL*Plus: Release 9.2.0.1.0 - Production on Thu Aug 12 10:45:59 2004

Copyright (c) 1982, 2002, Oracle Corporation. All rights reserved.


Connected to:
Oracle8i Enterprise Edition Release 8.1.7.4.0 - 64bit Production
With the Partitioning option
JServer Release 8.1.7.4.0 - 64bit Production


Session altered.

10:45:59 ***@***>
10:46:15 ***@***>
10:46:15 ***@***>
10:46:15 ***@***>set autoprint on
10:46:16 ***@***>variable x refcursor
10:46:16 ***@***>exec PKG_OPH_GOS.P_Get_Voucher ('QQQ','9',null,'N','PRACTITIONER_CODE',:x)

PL/SQL procedure successfully completed.


PAYMENT
-------
QQQ
QQQ
QQQ
QQQ
QQQ
QQQ
QQQ
QQQ
QQQ
QQQ
QQQ
QQQ

12 rows selected.

Elapsed: 00:00:00.00
Elapsed: 00:00:00.00
10:46:16 ***@***>
10:46:16 ***@***>
10:46:16 ***@***>select * from session_context;

NAMESPACE ATTRIBUTE
------------------------------ ------------------------------
VALUE
----------------------------------------------------------------------------------------------------
OPH_CTX CYCLE_IN_LIST_1
9


1 row selected.

Elapsed: 00:00:00.01
10:46:17 ***@***>set autoprint on
10:46:18 ***@***>variable x refcursor
10:46:18 ***@***>exec PKG_OPH_GOS.P_Get_Voucher ('QQQ','9',null,'N','PRACTITIONER_CODE',:x)
rec_Cur.Namespace = OPH_CTX
rec_Cur.Attribute = CYCLE_IN_LIST_1
BEGIN PKG_OPH_GOS.P_Get_Voucher ('QQQ','9',null,'N','PRACTITIONER_CODE',:x); END;

*
ERROR at line 1:
ORA-28106: input value for argument #1 is not valid
ORA-00911: invalid character
ORA-06512: at "SYS.DBMS_SESSION", line 58
ORA-06512: at "OP5.PKG_OPH_GOS", line 101
ORA-06512: at line 1


ERROR:
ORA-24338: statement handle not executed


SP2-0625: Error printing variable "x"
Elapsed: 00:00:00.00
Elapsed: 00:00:00.02
10:46:19 ***@***>
10:46:19 ***@***>
10:46:19 ***@***>select * from session_context;

NAMESPACE ATTRIBUTE
------------------------------ ------------------------------
VALUE
----------------------------------------------------------------------------------------------------
OPH_CTX CYCLE_IN_LIST_1
9


1 row selected.

Elapsed: 00:00:00.01
10:46:19 ***@***>







As you can see from a fresh sqlplus session it fails the second time i execute it due to there only being session context values after
the 2nd run. However if i then recompile the package, then select from session_context to show values still present then run it again
it works ok first time then fails again 2nd time:



10:51:49 ***@***>@C:\oph\packages\PKG_OPH_GOS.sql

Package body created.

Elapsed: 00:00:00.02
10:51:53 ***@***>select * from session_context;

NAMESPACE ATTRIBUTE
------------------------------ ------------------------------
VALUE
----------------------------------------------------------------------------------------------------
OPH_CTX CYCLE_IN_LIST_1
9


1 row selected.

Elapsed: 00:00:00.01
10:51:57 ***@***>exec PKG_OPH_GOS.P_Get_Voucher ('QQQ','9',null,'N','PRACTITIONER_CODE',:x)
rec_Cur.Namespace = OPH_CTX
rec_Cur.Attribute = CYCLE_IN_LIST_1

PL/SQL procedure successfully completed.


PAYMENT
-------
QQQ
QQQ
QQQ
QQQ
QQQ
QQQ
QQQ
QQQ
QQQ
QQQ
QQQ
QQQ

12 rows selected.

Elapsed: 00:00:00.02
Elapsed: 00:00:00.02
10:52:02 ***@***>
10:52:02 ***@***>
10:52:02 ***@***>select * from session_context;

NAMESPACE ATTRIBUTE
------------------------------ ------------------------------
VALUE
----------------------------------------------------------------------------------------------------
OPH_CTX CYCLE_IN_LIST_1
9


1 row selected.

Elapsed: 00:00:00.01
10:52:02 ***@***>exec PKG_OPH_GOS.P_Get_Voucher ('QQQ','9',null,'N','PRACTITIONER_CODE',:x)
rec_Cur.Namespace = OPH_CTX
rec_Cur.Attribute = CYCLE_IN_LIST_1
BEGIN PKG_OPH_GOS.P_Get_Voucher ('QQQ','9',null,'N','PRACTITIONER_CODE',:x); END;

*
ERROR at line 1:
ORA-28106: input value for argument #1 is not valid
ORA-00911: invalid character
ORA-06512: at "SYS.DBMS_SESSION", line 58
ORA-06512: at "OP5.PKG_OPH_GOS", line 101
ORA-06512: at line 1


ERROR:
ORA-24338: statement handle not executed


SP2-0625: Error printing variable "x"
Elapsed: 00:00:00.00
Elapsed: 00:00:00.02
10:53:47 ***@***>
10:53:47 ***@***>
10:53:47 ***@***>select * from session_context;

NAMESPACE ATTRIBUTE
------------------------------ ------------------------------
VALUE
----------------------------------------------------------------------------------------------------
OPH_CTX CYCLE_IN_LIST_1
9


1 row selected.

Elapsed: 00:00:00.01
10:53:48 ***@***>




What could be causing the ORA-28106, since you can see from the dbms_output that the first argument rec_Cur.Namespace looks ok

rec_Cur.Namespace = OPH_CTX




I'm sorry i tried to produce a test case using dummy tables but could not reproduce the problem.
When you change sql statement to reference 2 dummy tables and use the same package it will work correctly with no errors, i can't reproduce.
It seems to be dependent on the tables, which is strange as its complaining about setting a context.

Please do you know why i'm getting ORA-28106 ??

Thanks

Tom Kyte
August 12, 2004 - 9:11 am UTC

how's about a test case I too can run -- tables, data, et.al.

..

dxl, August 12, 2004 - 9:55 am UTC

i tried for a long time to reproduce a simple test case but couldn't, which makes me think it is bug related anyway.

I was just wondering if you have ever come across this sort of error anyway, and if you have any idea what could cause it??

If you look in the error message it seems to be complaining about an invalid character too, what could that be??

Tom Kyte
August 12, 2004 - 10:34 am UTC

Ok, got it.  

when plsql fetched from the table -- it was not null terminating the strings.  set_context for whatever reason was expecting null terminated strings.  I was able to reproduce in 817:

ops$tkyte@ORA817DEV> CREATE OR REPLACE CONTEXT OPH_CTX USING PKG_OPH_GOS;
 
Context created.
 
ops$tkyte@ORA817DEV>
ops$tkyte@ORA817DEV>
ops$tkyte@ORA817DEV>
ops$tkyte@ORA817DEV> CREATE OR REPLACE PACKAGE PKG_OPH_GOS
  2  AS
  3
  4          TYPE C_Return_Cursor IS REF CURSOR;
  5
  6      PROCEDURE P_Get_Voucher
  7      ( P_Org_String   IN    VARCHAR2 DEFAULT NULL,
  8        P_Cycle_String IN    VARCHAR2 DEFAULT NULL,
  9        P_Pract_String IN    VARCHAR2 DEFAULT NULL,
 10        P_Table_FLAG   IN    VARCHAR2,
 11        P_Order        IN    VARCHAR2,
 12        P_Cur          IN OUT     C_Return_Cursor    );
 13
 14  END PKG_OPH_GOS;
 15  /
 
Package created.
 
ops$tkyte@ORA817DEV>
ops$tkyte@ORA817DEV> CREATE OR REPLACE PACKAGE BODY PKG_OPH_GOS
  2  AS
  3
  4  PROCEDURE P_Get_Voucher
  5      ( P_Org_String   IN    VARCHAR2 DEFAULT NULL,
  6        P_Cycle_String IN    VARCHAR2 DEFAULT NULL,
  7        P_Pract_String IN    VARCHAR2 DEFAULT NULL,
  8        P_Table_FLAG   IN    VARCHAR2,
  9        P_Order        IN    VARCHAR2,
 10        P_Cur          IN OUT     C_Return_Cursor    )
 11  IS
 12     V_Org_String     VARCHAR2(32000);
 13     V_Cycle_String     VARCHAR2(32000);
 14     V_Pract_String     VARCHAR2(32000);
 15     l_n        NUMBER(38);
 16     l_query      varchar2(32000);
 17
 18     V_Table     VARCHAR2(10);
 19     V_Order        VARCHAR2(1000);
 20  BEGIN
 21      For rec_Cur IN
 22          (SELECT Namespace, Attribute
 23         FROM Session_Context
 24        WHERE Namespace = 'OPH_CTX'
 25          AND Attribute LIKE 'CYCLE\_IN\_LIST\_%' escape '\' )
 26          loop
 27                  dbms_output.put_line('rec_Cur.Namespace = "'|| rec_Cur.Namespace || '"' );
 28                  dbms_output.put_line('rec_Cur.Attribute = "'|| rec_Cur.Attribute || '"' );
 29          DBMS_SESSION.SET_CONTEXT( rec_Cur.Namespace, rec_Cur.Attribute, null);
 30      END LOOP;
 31
 32          V_Cycle_String := P_Cycle_String;
 33
 34      FOR i IN 1 .. 99999
 35          LOOP
 36          l_n := INSTR( V_Cycle_String, ',' );
 37          EXIT WHEN (NVL(l_n, 0) = 0 AND length(V_Cycle_String) IS NULL );
 38
 39          IF l_n = 0 THEN
 40              DBMS_SESSION.SET_CONTEXT
 41                          ( 'OPH_CTX', 'cycle_in_list_' || i, LTRIM(RTRIM(SUBSTR( V_Cycle_String, 1)) ));
 42              V_Cycle_String := NULL;
 43          ELSE
 44              DBMS_SESSION.SET_CONTEXT
 45                          ( 'OPH_CTX', 'cycle_in_list_' || i, LTRIM(RTRIM(SUBSTR( V_Cycle_String, 1, l_n-1)) ));
 46              V_Cycle_String := SUBSTR( V_Cycle_String, l_n+1 );
 47          END IF;
 48      END LOOP;
 49
 50          open p_cur for select * from dual;
 51  END P_Get_Voucher;
 52
 53  END PKG_OPH_GOS;
 54  /
 
Package body created.
 
ops$tkyte@ORA817DEV>
ops$tkyte@ORA817DEV>
ops$tkyte@ORA817DEV> set autoprint on
ops$tkyte@ORA817DEV> variable x refcursor
ops$tkyte@ORA817DEV> exec PKG_OPH_GOS.P_Get_Voucher('QQQ','9',null,'N','PRACTITIONER_CODE',:x)
 
PL/SQL procedure successfully completed.
 
 
D
-
X
 
ops$tkyte@ORA817DEV> exec PKG_OPH_GOS.P_Get_Voucher('QQQ','9',null,'N','PRACTITIONER_CODE',:x)
rec_Cur.Namespace = "OPH_CTX"
rec_Cur.Attribute = "CYCLE_IN_LIST_1"
BEGIN PKG_OPH_GOS.P_Get_Voucher('QQQ','9',null,'N','PRACTITIONER_CODE',:x); END;
 
       *
ERROR at line 1:
ORA-28106: input value for argument #1 is not valid
ORA-00911: invalid character
ORA-06512: at "SYS.DBMS_SESSION", line 62
ORA-06512: at "OPS$TKYTE.PKG_OPH_GOS", line 29
ORA-06512: at line 1



<b>the workaround is fairly simple and not needed in 9i and up</b>


 26          loop
 27                  dbms_output.put_line('rec_Cur.Namespace = "'|| rec_Cur.Namespace || '"' );
 28                  dbms_output.put_line('rec_Cur.Attribute = "'|| rec_Cur.Attribute || '"' );
 29          DBMS_SESSION.SET_CONTEXT( rec_Cur.Namespace<b>||'', </b>rec_Cur.Attribute<b>||''</b>, null);
 30      END LOOP;



alternatively, just assign the variable to itself, that'll null terminate it as well. 

thanks!

dxl, August 12, 2004 - 12:01 pm UTC

Thanks Tom that was truly amazing that you were not only able to reproduce the error but also offered a fix.

I was able to implement the fix ok without problems and its working great now.

Just out of interest though can you give a bit more detail as to what was going on?
I'm not sure i totally understood why it was happening, what was actually the "not null" bit on the end of the strings?
Which bit of your test case actually forced the problem to occur??

Many thanks


Tom Kyte
August 12, 2004 - 12:36 pm UTC

it is an intermittent bug in 8i with the context value. if you:

select something into plsql_variable from table;

in 8i - the plsql_variable was not "null terminated" (a C language'ism). If you assigned plsql_variable := plsql_variable - it is.

sys_context was assuming null terminated.

hence when you sent it the variable without the null terminator, it failed IF the string wasn't accidently null terminated (which it could be). it depends on what bytes were left lying about in memory.

creating the temporary plsql variable via the ||'' is like doing an assignment.

Return a weak ref cursor with datatypes

Doug, August 12, 2004 - 4:45 pm UTC

The client is Java using a JDBC connection.

Thanks Tom

Tom Kyte
August 12, 2004 - 4:53 pm UTC

they work just as functionally with weak as with strongly typed -- why do you need a strongly typed cursor?

My production solution

Michael, August 20, 2004 - 2:42 am UTC

Hello,

i used package variables and package functions to solve this problem. This approach works very well in production.

CREATE TYPE NUMBERTABLE AS TABLE OF NUMBER;

CREATE OR REPLACE PACKAGE BIND_TEST_PKG as
function getEnameFilter return emp.ename%type;
function getDeptnoFilterTable return numbertable;
function getSalUpperLimit return emp.sal%type;
function getSalLowerLimit return emp.sal%type;

function getCursor(p_ename in emp.ename%type := null,
p_deptno in numbertable := null,
p_sal_lowerlimit in emp.sal%type := null,
p_sal_upperlimit in emp.sal%type := null)
return sys_refcursor;
end;

CREATE OR REPLACE PACKAGE BODY BIND_TEST_PKG as
g_Ename emp.ename%type := null;
g_DeptnoTable numbertable := null;
g_SalUpperLimit emp.sal%type := null;
g_SalLowerLimit emp.sal%type := null;

function getEnameFilter return emp.ename%type as
begin
return g_Ename;
end;

function getDeptnoFilterTable return numbertable as
begin
return g_DeptnoTable;
end;

function getSalUpperLimit return emp.sal%type as
begin
return g_SalUpperLimit;
end;

function getSalLowerLimit return emp.sal%type as
begin
return g_SalLowerLimit;
end;

function getCursor(p_ename in emp.ename%type := null,
p_deptno in numbertable := null,
p_sal_lowerlimit in emp.sal%type := null,
p_sal_upperlimit in emp.sal%type := null)
return sys_refcursor
as
l_cursor sys_refcursor;
l_query varchar2(2000) := 'select e.empno, e.ename, e.sal, e.deptno ' ||
'from emp e ' ||
'where 1 = 1 ';
begin
if p_ename is not null then
g_Ename := p_ename;
l_query := l_query || 'and e.ename like bind_test_pkg.getEnameFilter || ''%'' ';
end if;
if p_deptno is not null then
g_DeptnoTable := p_deptno;
l_query := l_query || 'and e.deptno in (select column_value ' ||
'from table(bind_test_pkg.getDeptnoFilterTable)) ';
end if;
if p_sal_lowerlimit is not null and p_sal_upperlimit is not null then
g_SalUpperLimit := p_sal_upperlimit;
g_SalLowerLimit := p_sal_lowerlimit;
l_query := l_query || 'and e.sal between bind_test_pkg.getSalLowerLimit and bind_test_pkg.getSalUpperLimit ';
elsif p_sal_lowerlimit is not null then
g_SalLowerLimit := p_sal_lowerlimit;
l_query := l_query || 'and e.sal >= bind_test_pkg.getSalLowerLimit ';
elsif p_sal_upperlimit is not null then
g_SalUpperLimit := p_sal_upperlimit;
l_query := l_query || 'and e.sal <= bind_test_pkg.getSalUpperLimit ';
end if;
open l_cursor for l_query;
return l_cursor;
end;
end;

I think this works as good as the sys_context solution, or even better, because it's easy to do in-lists (deptno in this example) and you have no datatype conversions.

Tom, do you see any drawback of this solution?

Tom Kyte
August 20, 2004 - 10:56 am UTC

yes, performance is less then "good" in general.

the overhead of calling plsql from sql is huge compared to using sys_context. this could be *deadly* in general. I would (and do) avoid this approach. It is what we had to do in v7/v8.0 but not anymore.

at the *very least* -- use:

and e.sal <= (select bind_test_pkg.getSalUpperLimit from dual)

use scalar subqueries so that the scalar subquery caching can kick in and invoke your function once per query instead of one per row per query.

You are right ...

Michael, August 25, 2004 - 7:00 am UTC

Hi,

Yes, the scalar subquery caching works great!!!
Thank-you very much for this tip!

To compare the sys_context with the package variables, i made the following test (with RUNSTATS_PKG):

The package:

CREATE OR REPLACE PACKAGE BIND_TEST_PKG as
function getEnameFilter return emp.ename%type;

function getCursor1(p_ename in emp.ename%type := null)
return sys_refcursor;

function getCursor2(p_ename in emp.ename%type := null)
return sys_refcursor;
end;

getCursor1 uses the package variable and a package function. getCursor2 uses a context.

CREATE OR REPLACE PACKAGE BODY BIND_TEST_PKG as
g_Ename emp.ename%type := null;

function getEnameFilter return emp.ename%type as
begin
return g_Ename;
end;

function getCursor1(p_ename in emp.ename%type := null)
return sys_refcursor
as
l_cursor sys_refcursor;
l_query varchar2(2000) := 'select e.empno, e.ename, e.sal, e.deptno ' ||
'from emp e ' ||
'where 1 = 1 ';
begin
if p_ename is not null then
g_Ename := p_ename;
l_query := l_query || 'and e.ename like (select bind_test_pkg.getEnameFilter || ''%'' from dual) ';
end if;
open l_cursor for l_query;
return l_cursor;
end;

function getCursor2(p_ename in emp.ename%type := null)
return sys_refcursor
as
l_cursor sys_refcursor;
l_query varchar2(2000) := 'select e.empno, e.ename, e.sal, e.deptno ' ||
'from emp e ' ||
'where 1 = 1 ';
begin
if p_ename is not null then
dbms_session.set_context('bind_test_ctx', 'ename', p_ename);
l_query := l_query || 'and e.ename like sys_context(''bind_test_ctx'', ''ename'') || ''%'' ';
end if;
open l_cursor for l_query;
return l_cursor;
end;
end;

The context:

create context bind_test_ctx using bind_test_pkg;

Then i executed the following test (the query returns from my emp table about 100 rows):

declare
c sys_refcursor;
type l_numtab_t is table of number;
type l_varchartab_t is table of varchar2(40);
l_empno l_numtab_t;
l_ename l_varchartab_t;
l_sal l_numtab_t;
l_deptno l_numtab_t;
begin
runstats_pkg.rs_start;
for l_i in 1 .. 1000 loop
c := bind_test_pkg.getCursor1(p_ename => 'EMP7');
fetch c bulk collect into l_empno, l_ename, l_sal, l_deptno;
close c;
end loop;
runstats_pkg.rs_middle;
for l_i in 1 .. 1000 loop
c := bind_test_pkg.getCursor2(p_ename => 'EMP7');
fetch c bulk collect into l_empno, l_ename, l_sal, l_deptno;
close c;
end loop;
runstats_pkg.rs_stop;
end;

Result of run 1:
================

Run1 ran in 302 hsecs
Run2 ran in 287 hsecs
run 1 ran in 105,23% of the time

Name Run1 Run2 Diff
LATCH.active checkpoint queue 2 1 -1
LATCH.kwqit: protect wakeup ti 0 1 1
LATCH.spilled msgs queues list 0 1 1
STAT...redo entries 6 7 1
LATCH.session timer 1 0 -1
LATCH.Consistent RBA 1 3 2
LATCH.cache buffer handles 0 2 2
LATCH.dummy allocation 2 0 -2
LATCH.process allocation 2 0 -2
LATCH.process group creation 2 0 -2
LATCH.event group latch 2 0 -2
LATCH.channel handle pool latc 2 0 -2
LATCH.lgwr LWN SCN 0 3 3
STAT...cleanout - number of kt 2 5 3
STAT...consistent gets - exami 1,002 1,005 3
STAT...calls to kcmgcs 2 5 3
LATCH.mostly latch-free SCN 0 3 3
STAT...active txn count during 2 5 3
LATCH.cache buffers lru chain 28 24 -4
STAT...parse time elapsed 3 7 4
STAT...parse time cpu 3 7 4
LATCH.messages 14 19 5
STAT...recursive cpu usage 215 220 5
LATCH.redo writing 7 12 5
STAT...consistent changes 10 15 5
LATCH.session idle bit 6 1 -5
STAT...db block changes 16 22 6
STAT...db block gets 10 17 7
LATCH.channel operations paren 10 2 -8
LATCH.enqueues 15 6 -9
LATCH.row cache enqueue latch 0 54 54
LATCH.row cache objects 0 54 54
LATCH.checkpoint queue latch 136 70 -66
LATCH.session allocation 4 92 88
LATCH.simulator hash latch 10,116 9,984 -132
STAT...redo size 1,744 1,876 132
LATCH.redo allocation 8 147 139
LATCH.undo global data 3 190 187
LATCH.dml lock allocation 0 190 190
LATCH.enqueue hash chains 15 284 269
LATCH.library cache 10,006 9,375 -631
STAT...buffer is not pinned co 23,000 22,000 -1,000
STAT...table scans (short tabl 1,000 0 -1,000
STAT...table scan rows gotten 1,000 0 -1,000
STAT...table scan blocks gotte 1,000 0 -1,000
STAT...no work - consistent re 23,000 22,000 -1,000
LATCH.shared pool 4,003 5,212 1,209
LATCH.library cache pin 8,006 6,188 -1,818
STAT...calls to get snapshot s 3,001 1,001 -2,000
LATCH.library cache pin alloca 2,000 4,160 2,160
STAT...session logical reads 27,015 24,026 -2,989
STAT...consistent gets 27,005 24,009 -2,996
LATCH.cache buffers chains 53,143 48,419 -4,724
STAT...session pga memory 262,144 196,608 -65,536

Run1 latches total versus runs -- difference and pct
Run1 Run2 Diff Pct
87,601 84,564 -3,037 103.59%

Result of run 2:
================

Run1 ran in 281 hsecs
Run2 ran in 313 hsecs
run 1 ran in 89,78% of the time

Name Run1 Run2 Diff
LATCH.Consistent RBA 1 2 1
LATCH.active checkpoint queue 1 2 1
LATCH.enqueues 6 7 1
LATCH.session idle bit 0 1 1
LATCH.spilled msgs queues list 0 1 1
LATCH.kwqit: protect wakeup ti 0 1 1
LATCH.cache buffer handles 0 2 2
LATCH.lgwr LWN SCN 0 2 2
LATCH.simulator hash latch 9,986 9,984 -2
STAT...parse time cpu 5 7 2
LATCH.mostly latch-free SCN 0 2 2
STAT...redo entries 6 9 3
LATCH.redo writing 6 10 4
STAT...parse time elapsed 5 9 4
STAT...active txn count during 2 7 5
STAT...calls to kcmgcs 2 7 5
STAT...cleanout - number of kt 2 7 5
STAT...consistent gets - exami 1,002 1,007 5
LATCH.messages 10 18 8
STAT...consistent changes 10 23 13
STAT...db block gets 10 23 13
STAT...db block changes 16 32 16
STAT...recursive cpu usage 224 204 -20
LATCH.row cache enqueue latch 0 54 54
LATCH.row cache objects 0 54 54
LATCH.cache buffers lru chain 0 61 61
LATCH.session allocation 0 92 92
LATCH.checkpoint queue latch 48 168 120
LATCH.redo allocation 8 147 139
LATCH.undo global data 4 193 189
LATCH.dml lock allocation 0 190 190
LATCH.enqueue hash chains 6 286 280
STAT...redo size 1,744 2,124 380
LATCH.library cache 10,006 9,375 -631
STAT...buffer is not pinned co 23,000 22,000 -1,000
STAT...table scans (short tabl 1,000 0 -1,000
STAT...table scan rows gotten 1,000 0 -1,000
STAT...table scan blocks gotte 1,000 0 -1,000
STAT...no work - consistent re 23,000 22,000 -1,000
LATCH.shared pool 4,001 5,212 1,211
LATCH.library cache pin 8,006 6,188 -1,818
STAT...calls to get snapshot s 3,001 1,001 -2,000
LATCH.library cache pin alloca 2,000 4,160 2,160
STAT...session logical reads 27,015 24,036 -2,979
STAT...consistent gets 27,005 24,013 -2,992
LATCH.cache buffers chains 53,079 48,567 -4,512
STAT...session pga memory 65,536 262,144 196,608

Run1 latches total versus runs -- difference and pct
Run1 Run2 Diff Pct
87,238 84,849 -2,389 102.82%

Result of run 3:
================

Run1 ran in 269 hsecs
Run2 ran in 297 hsecs
run 1 ran in 90,57% of the time

Name Run1 Run2 Diff
LATCH.active checkpoint queue 1 2 1
LATCH.redo allocation 9 10 1
LATCH.undo global data 3 4 1
STAT...physical reads 1 0 -1
LATCH.redo writing 6 7 1
STAT...redo entries 6 7 1
LATCH.simulator hash latch 9,986 9,984 -2
STAT...cleanout - number of kt 2 4 2
STAT...consistent gets - exami 1,002 1,004 2
STAT...calls to kcmgcs 2 4 2
STAT...active txn count during 2 4 2
STAT...recursive cpu usage 224 226 2
LATCH.messages 9 12 3
STAT...parse time cpu 3 6 3
STAT...parse time elapsed 3 7 4
STAT...consistent changes 10 15 5
STAT...db block changes 16 23 7
STAT...db block gets 10 17 7
LATCH.cache buffers lru chain 1 29 28
LATCH.checkpoint queue latch 53 146 93
STAT...redo size 1,748 1,928 180
LATCH.library cache 10,006 9,012 -994
STAT...buffer is not pinned co 23,000 22,000 -1,000
STAT...table scans (short tabl 1,000 0 -1,000
STAT...table scan rows gotten 1,000 0 -1,000
STAT...table scan blocks gotte 1,000 0 -1,000
STAT...no work - consistent re 23,000 22,000 -1,000
LATCH.shared pool 4,001 5,003 1,002
LATCH.library cache pin 8,006 6,012 -1,994
LATCH.library cache pin alloca 2,000 4,000 2,000
STAT...calls to get snapshot s 3,001 1,001 -2,000
STAT...session logical reads 27,015 24,025 -2,990
STAT...consistent gets 27,005 24,008 -2,997
LATCH.cache buffers chains 53,071 47,174 -5,897
STAT...session pga memory 262,144 196,608 -65,536

Run1 latches total versus runs -- difference and pct
Run1 Run2 Diff Pct
87,233 81,476 -5,757 107.07%

Result of run 4:
================

Run1 ran in 275 hsecs
Run2 ran in 254 hsecs
run 1 ran in 108,27% of the time

Name Run1 Run2 Diff
LATCH.Consistent RBA 1 0 -1
LATCH.archive process latch 1 0 -1
LATCH.simulator lru latch 0 1 1
STAT...free buffer requested 0 1 1
LATCH.redo allocation 8 7 -1
STAT...parse time cpu 3 2 -1
STAT...parse time elapsed 3 2 -1
LATCH.archive control 2 0 -2
LATCH.redo writing 5 3 -2
STAT...redo entries 6 8 2
LATCH.simulator hash latch 9,988 9,985 -3
LATCH.cache buffers lru chain 1 5 4
LATCH.messages 11 6 -5
STAT...consistent gets - exami 1,002 1,007 5
STAT...cleanout - number of kt 2 7 5
STAT...calls to kcmgcs 2 7 5
STAT...active txn count during 2 7 5
LATCH.undo global data 4 10 6
STAT...consistent changes 10 20 10
STAT...db block changes 16 29 13
STAT...db block gets 10 24 14
STAT...recursive cpu usage 230 195 -35
STAT...redo size 1,752 2,060 308
LATCH.library cache 10,006 9,012 -994
STAT...buffer is not pinned co 23,000 22,000 -1,000
STAT...no work - consistent re 23,000 22,000 -1,000
STAT...table scan blocks gotte 1,000 0 -1,000
STAT...table scans (short tabl 1,000 0 -1,000
STAT...table scan rows gotten 1,000 0 -1,000
LATCH.shared pool 4,001 5,003 1,002
LATCH.library cache pin 8,006 6,012 -1,994
LATCH.library cache pin alloca 2,000 4,000 2,000
STAT...calls to get snapshot s 3,001 1,001 -2,000
STAT...session logical reads 27,015 24,036 -2,979
STAT...consistent gets 27,005 24,012 -2,993
LATCH.cache buffers chains 53,084 47,155 -5,929
STAT...session pga memory 262,144 196,608 -65,536

Run1 latches total versus runs -- difference and pct
Run1 Run2 Diff Pct
87,254 81,335 -5,919 107.28%

Performance-wise they are nearly identical (there is some "noise").
The package solution needs a little more latches (2-7%), but it's not dramatic.
So, i think - in the end - the package solution (getCursor1 with scalar subquery caching of course!) is better, because you can't have type conversion issues and, above all, you can use in-lists.

Or has my test an error/misinterpretation?

How can we Use subquery in Sys_Context

Alex, August 28, 2004 - 5:04 pm UTC

Hi Tom,

let's suppose p_program_name is procedure's parameter and it's checked as

If p_program_name is not null then
lv_where := lv_where ||'epnh.education_program_name_id IN
( Select hist.education_program_name_id
From education_pgm_name_hist hist
Where hist.uppercase_program_name like "'
||p_program_name||'")';
End If;

How can this situtaion be used in sys_context?

Thanks.

Tom Kyte
August 28, 2004 - 5:11 pm UTC

the subquery isn't really relevant in this context. this is not any different than what is demonstrated above:

dbms_session.set_context( 'my_ctx', 'prog_name', p_program_name );

lv_where := lv_where ||'epnh.education_program_name_id IN
( Select hist.education_program_name_id
From education_pgm_name_hist hist
Where hist.uppercase_program_name
like sys_context( ''my_ctx'', ''prog_name'' ) )';




Reference the column or a variable ?

robert, September 02, 2004 - 10:20 am UTC


for i in cursor_x
loop
*** whole lot of repeated references to i.columnx ***
end loop;


for situation like above
Is it more performent to assign i.columnx to a variable & reference that var or makes no difference ?

Thanks

Tom Kyte
September 02, 2004 - 10:52 am UTC

benchmark it and let us know!

Seems No Difference to me....

robert, September 02, 2004 - 11:12 am UTC

nope, no difference that I could tell.
My sample is a loop size of 500 and about 30 repeated refernces to i.columnx

thanks

varying select list

koola, October 12, 2004 - 12:44 pm UTC

Tom

We are building packages for a java app to call. This is so that we have no sql statements embedded in the java app, all our sql will reside in packaged procedures stored in the database.

Now there is a requirement to have a "filter" page in the app. This will need to calculate lots of different counts from a few tables depending on how the user filters the data and what they choose to "group by" to do the count(*).

Someone has suggested that we build a table and fill a column with the text for all the different "base" queries

eg Query_Table:

Query_id TABLE_NAME GROUP_BY_FIELDS
--------- ----------- ----------------
1 tble1 col1, col2, co3
2 tble1 col1, col2


That type of thing.
Then they would use the text in these fields to dynamically build a query:

procedure (returning ref_cursor) etc..


....
select table_name, group_by_fields
into v_table_name, v_group
from ...

..
v_Sql := 'select ...' from ' || V_table_name || '..etc.
||' where id = :id || 'group by '|| v_group

open V_REF_CURSOR FOR V_Sql using v_id;

etc


Do you get the idea?! At the moment there are 20 to 30 different combinations of group by clauses to produce the counts required. So this would save writing 20 to 30 stored procedures and just put the queries in a table.

Now i am totally against this idea but i am having trouble explaining to them why! Would it flooding the shared pool with unique sql??

Their arguement is that:

1) as far as binds go the WHERE clause arguement ie the id, is passed in using bind variables so thats ok.

2) It makes it very easy to build the queries dynamically like this using a table, since it makes it easy to update and add to the queries we are able to run and each query will eventually make it in to the shared_pool once it is used.

3) The system is only going to be used by 100 users at most so its not like there are going to be 1000s of unique sql statements in the shared pool.






Please can you help me give reasons why this is not a good idea (unless you think it is valid enough) maybe with some examples to prove it?



My alternative approach would involve passing in to the procedure an array of select columns ?? and using application contexts to bind the data ??
Not sure about the group by clauses though? maybe use dbms_sql to build the queries?? but would this still involve a lot more procedures, i'm not sure?


This is on 9.2.0.5.

Can you suggest anything better?

Many thanks


Tom Kyte
October 12, 2004 - 2:08 pm UTC

<quote>
v_Sql := 'select ...' from ' || V_table_name || '..etc.
||' where id = :id || 'group by '|| v_group
...
Would it flooding the shared pool with unique sql??
</quote>

not the way you show it -- that uses a bind variable -- everyone that used the same "filter" would get the same query -- there would be at most 20-30 queries right? (if replacing 20-30 stored procedures)...


As long as the queries are made "consistently the same way" - as the table driven procedure would do, this will work just fine (although for just 20/30 queries, not sure it is worth it -- unless you expect this to go to 200/300 queries over time).

In this case, either static or dynamic sql would be OK, and the dynamic sql just needs to be constructed "in the same manner" so it is not unique -- and this seems to fit that fine.

A reader, November 15, 2004 - 4:38 pm UTC

I need to write a SP takes 5 inputs and returns a refcursor. The query is determined by any of the 5 input parameters that are non-null, just like the original question on this thread.

I guess your original answer still stands? That was for 8i, how would it change using 9iR2 and sys_refcursor? Do I still need to use application contexts?

How would it go?

create or replace context c using p
/

create or replace procedure p (p_i in varchar2,p_j varchar2,
p_rc in out sys_refcursor)
is
l_sql long;
begin
l_sql := 'select ... from ... where 1=1 ';
if (p_i is not null) then
dbms_session.set_context(...);
l_sql := l_sql || ' and i = sys_context...'
end if;

...

open p_rc for l_sql;

end;

Does that look right?

Thanks

Tom Kyte
November 15, 2004 - 9:17 pm UTC

a sys_refcursor is just a predefined type, saves you have having to define your own.

would be the same otherwise.

Very helpful, but ....

David, November 17, 2004 - 4:39 am UTC

Tom,



Great example, as usual, but given the number of possible inputs this does mean 'x' number of possible cache'd queries in the shared pool. We have a similar situation, where many differing inputs could result in the same query being executed, but with just different WHERE clauses. In your example using contexts, this means for every combination of inputs there will be another SQL statement parsed. Our query is a large view, so each statement is large in itself (in terms of bytes) so quickly fills up the SGA.

My question is this.. Is there any way to do this context trick, but only using 1 parsed query in the shared pool?

I've tried doing things like

...
AND col1 = NVL(p_col1, col1)
AND col2 = NVL(p_col2, col2)
etc..

which works in a logical sense, but runs like a dog due to the indexes not being used. I've resorted to creating multiple views based around the most popular inputs, but would like a neater solution.

Any help/comments appreciated. We're on ORACLE 8i (v8.1.7.4.0)

Great site BTW.

David.

Tom Kyte
November 17, 2004 - 10:36 am UTC

say you have 3 columns...

each column is indexed...

each column could use an index nicely.  

you build one query with:

select * from t
where col1 = nvl(p_col1, col1 )
  and col2 = nvl(p_col2, col2 )
  and col3 = nvl(p_col3, col3 )


now, how many plans would there be?  one.

How many plans do you want to have?  at least 3 in this case.

What would that one plan be?  well, it would be optimal for "col3 = " and suboptimal for the rest.  consider:



ops$tkyte@ORA817DEV> create table t
  2  as
  3  select rownum c1, rownum c2, rownum c3,
  4         rpad('*',80,'*') data
  5    from all_objects;
 
Table created.
 
ops$tkyte@ORA817DEV>
ops$tkyte@ORA817DEV> create index t_idx1 on t(c1);
 
Index created.
 
ops$tkyte@ORA817DEV> create index t_idx2 on t(c2);
 
Index created.
 
ops$tkyte@ORA817DEV> create index t_idx3 on t(c3);
 
Index created.
 
ops$tkyte@ORA817DEV>
ops$tkyte@ORA817DEV> exec dbms_stats.gather_table_stats( user, 'T', cascade => true );
 
PL/SQL procedure successfully completed.
 
ops$tkyte@ORA817DEV>
ops$tkyte@ORA817DEV> variable c1 number
ops$tkyte@ORA817DEV> variable c2 number
ops$tkyte@ORA817DEV> variable c3 number
ops$tkyte@ORA817DEV> exec :c1 := 1;
 
PL/SQL procedure successfully completed.
 
ops$tkyte@ORA817DEV> @trace
ops$tkyte@ORA817DEV> alter session set events '10046 trace name context forever, level 12';
 
Session altered.
 
ops$tkyte@ORA817DEV> select *
  2    from t t1
  3   where c1 = nvl(:c1,c1)
  4     and c2 = nvl(:c2,c2)
  5     and c3 = nvl(:c3,c3)
  6  /

<b>tkprof says...</b>

select *
  from t t1
 where c1 = nvl(:c1,c1)
   and c2 = nvl(:c2,c2)
   and c3 = nvl(:c3,c3)
                                                                                                      
Rows     Row Source Operation
-------  ---------------------------------------------------
      1  CONCATENATION
      1   FILTER
      1    TABLE ACCESS FULL T
      0   FILTER
      0    TABLE ACCESS BY INDEX ROWID T
      0     INDEX RANGE SCAN (T_IDX3)

<b>so, it would optimize the c3=nvl(:c3,c3) but not all of the combinations</b>

my point at the end here is.....

with this above technique you generate a FINITE (small relatively speaking) number of distinct sql's (the goal is not "1" sql or "42" sql's the goal is a finite number of sql's) and you size your shared pool accordingly.  You won't have millions of statements, you'll have dozens and that you can size for.
 
 

cursor

bhagirath pesaru, November 22, 2004 - 7:01 am UTC

very good thanks

Using bind variables

Sanjaya Balasuriya, November 29, 2004 - 8:16 pm UTC

Hi Tom,

I'm trying to write a code to get the row count of all the tables my schema. (just to try dynamic SQL).

When I write;
for x in (select table_name from user_tables)
loop
execute immediate 'select count(*) from '||x.table_name into tc;
dbms_output.putline(tc);
end loop;

it works fine. But no bind variables have been used. Since "x.table_name" is a PL/SQL variable it should be bound no ?

Then I tried;

for x in (select table_name from user_tables)
loop
execute immediate 'select count(*) from :1' into tc using x.table_name;
end loop;

Now it says "invalid table name". What should be the syntax here ?

Thanks in advance.

-San

Tom Kyte
November 29, 2004 - 8:23 pm UTC

you cannot "bind" an identifier. the plans change for each on.

you can only bind where you could put a literal.


select * from t where x = 'X'

means 'X' could be bound, but

select * from 'T' where x = 'X';

shows that 'T' cannot be bound, it doesn't make sense.


You cannot bind the table name -- the plans change for each and every query.

Just another idea ...

Michael, November 30, 2004 - 3:27 am UTC

Hi!

Here is another idea to solve the problem:

CREATE TYPE VARCHAR2TABLE AS TABLE OF VARCHAR2(4000);

CREATE OR REPLACE PACKAGE BIND_TEST_PKG  as  
    
  function getCursor3(p_dname in varchar2table := null,
                      p_ename in emp.ename%type := null)
    return sys_refcursor;    
    
end;

CREATE OR REPLACE PACKAGE BODY BIND_TEST_PKG as
  
  function getCursor3(p_dname in varchar2table := null,
                      p_ename in emp.ename%type := null)
    return sys_refcursor
  as
    l_cursor sys_refcursor;
    l_query varchar2(2000) := 'select e.empno, e.ename, e.sal, e.dname ' ||
                              'from   (select e2.empno, e2.ename, e2.sal, d.dname ' ||
                              '        from   emp e2, dept d ' ||
                              '        where  e2.deptno = d.deptno) e ' ||
                              'where  1 = 1 ';
  begin
    if p_dname is not null then
      l_query := l_query || 'and e.dname in (select column_value ' ||
                                             'from  table(cast(:dname as varchar2table))) ';
    else
      l_query := l_query || 'and (:dname is null or 1=1) ';                                         
    end if;
    if p_ename is not null then
      l_query := l_query || 'and e.ename like :ename || ''%'' ';
    else
      l_query := l_query || 'and (:ename is null or 1=1) ';
    end if;
    open l_cursor for l_query using p_dname, p_ename;
    return l_cursor;
  end;        

end;

Test:

SQL> ed
Datei afiedt.buf wurde geschrieben

  1  begin
  2    :c := bind_test_pkg.getCursor3(
  3        p_dname => varchar2table('ACCOUNTING', 'RESEARCH'),
  4        p_ename => 'EMP234');
  5* end;
SQL> /

PL/SQL-Prozedur wurde erfolgreich abgeschlossen.

SQL> print c

     EMPNO ENAME             SAL DNAME
---------- ---------- ---------- --------------
      3340 EMP2340       6378,37 ACCOUNTING
      3343 EMP2343       4213,17 ACCOUNTING
      3345 EMP2345       2360,47 ACCOUNTING
      3347 EMP2347       4192,19 ACCOUNTING
      3349 EMP2349       3216,77 ACCOUNTING
      3342 EMP2342       6875,46 RESEARCH
      3344 EMP2344       3141,76 RESEARCH
      3346 EMP2346       2376,16 RESEARCH
      3348 EMP2348       2926,88 RESEARCH

9 Zeilen ausgewõhlt.

SQL>

It works with simple binds, and binds always all possible filters. When a filter is not needed it is bound in a way so that it is obviously - for the database - irrelevant.

It seems to work ... in my test environment.

So, what's your opinion about this idea? 

Tom Kyte
November 30, 2004 - 7:40 am UTC

it is very much almost the same as the decode suggestion above by Darko Egersdorfer from South Africa

Doubt on Cursor

TH, December 02, 2004 - 4:21 am UTC

Dear Tom, Please see this.

Table Employees
------------------
EMP_ID,
NAME,
CATEGORY,



CATEGORY can be 'A' or 'B' or 'C'


I have one cursor:


cursor cur_emp(my_type varchar2(1))
is select * from employees where
category=decode(my_type,'1','A','2', ????? ) ;



My_type will take two values '1' or '2'


If I pass '1' it should bring employees with category 'A'. And If I pass '2' it should bring the employees with category 'B' or 'C'.


What is the simple solution?
Can I apss an operator as a parameter ('=' and '<>')?

Thanks in advance,

TH, BAH


Tom Kyte
December 02, 2004 - 7:43 am UTC

in your case,


where category in ( decode(my_type,'1','A'),
decode(my_type,'2','B'),
decode(my_type,'2','C') );


you cannot "pass" an operator, that would require an entirely different query with an entirely different execution plan.

Just Beautiful!

TH, December 04, 2004 - 2:28 am UTC

Thanks..

Just Beautiful!

TH, BAH


Passing a ResultSet as Ref Cursor

A reader, December 04, 2004 - 4:16 pm UTC

Hi Tom,

I am trying to bind a ResultSet object as a pl/sql ref cursor to an OracleCallableStatement in Java. I tried using the deprecated setCursor() with no success. Is this possible in 9i or 10g?

Thanks.

Tom Kyte
December 04, 2004 - 8:18 pm UTC

have you tried the documented ways?

why would you use a deprecated function in new code?


</code> http://asktom.oracle.com/~tkyte/ResultSets/index.html <code>

Passing a ResultSet as Ref Cursor

A reader, December 05, 2004 - 1:29 pm UTC

I am not trying to bind a cursor returned from a function as a ResultSet. I'm trying to bind a ResultSet object as a parameter to a pl/sql procedure. Is there a way to do this other than the deprecated setCursor(int, ResultSet)?

Tom Kyte
December 05, 2004 - 7:03 pm UTC

ref cursors go OUT from plsql, there isn't a way to send them IN (where would they "come from"?)

Very useful but having a few problems!

Siobhan, December 09, 2004 - 2:23 pm UTC

I have created a procedure based on your sample code as follows:

create or replace package pkgSelectClient as

type rc is REF CURSOR;

procedure prcSelectClient( p_surname in varchar2 default NULL,
p_dob in date default NULL,
p_inumber in number default NULL,
c_results in out rc);

end pkgSelectClient;
/

create or replace package body pkgSelectClient as

procedure prcSelectClient( p_surname in varchar2 default NULL,
p_dob in date default NULL,
p_inumber in number default NULL,
c_results in out rc) is


l_query varchar2(512) default 'select * from t_Client where 1 = 1 ';

cursor l_template is select * from t_Client;
l_rec l_template%rowtype;

begin

if ( p_surname is NOT NULL ) then
dbms_session.set_context( 'MY_CTX', 'SURNAME', '%'||upper(p_surname)||'%');
l_query := l_query || ' and SURNAME like sys_context( ''MY_CTX'', ''SURNAME'' ) ';
end if;

if ( p_DOB is NOT NULL ) then
dbms_session.set_context( 'MY_CTX', 'DOB', to_char(p_DOB,'yyyymmddhh24miss'));
l_query := l_query || ' and DOB > to_date(sys_context( ''MY_CTX'',''DOB'' ),''yyyymmddhh24miss'') ';
end if;


if ( p_INUMBER is NOT NULL ) then
dbms_session.set_context( 'MY_CTX', 'INUMBERL', p_INUMBER);
l_query := l_query || ' and INUMBER > to_number(sys_context( ''MY_CTX'',''INUMBER'' )) ';
end if;

open c_results for l_query;

end;

end pkgSelectClient;
/
create or replace context MY_CTX using prcSelectClient;
/


When I try and test using the following SQL Script:

VAR C REFCURSOR
execute lcid.prcSelectClient('SIOBHAN','01-JAN-1980',1,:c);
Print c

I get:

BEGIN lcid.prcSelectClient('SIOBHAN','01-JAN-1980',1,:c); END;

*
ERROR at line 1:
ORA-06550: line 1, column 7:
PLS-00306: wrong number or types of arguments in call to 'PRCSELECTCLIENT'
ORA-06550: line 1, column 7:
PL/SQL: Statement ignored


ERROR:
ORA-24338: statement handle not executed


SP2-0625: Error printing variable "c"

Am I doing something stupid (most likely!)?

Also - this is Version 9.2.0.1.0 but it will also have to run against 7.3.4 (!!) Am I right in thinking this will not work and what was would i do the same thing for Version 7

Many thanks


Tom Kyte
December 09, 2004 - 3:30 pm UTC

you

execute lcid.prcSelectClient('SIOBHAN','01-JAN-1980',1,:c);

but you programmed:

create or replace package pkgSelectClient as

type rc is REF CURSOR;

procedure prcSelectClient( p_surname in varchar2 default NULL,
p_dob in date default NULL,
p_inumber in number default NULL,
c_results in out rc);

end pkgSelectClient;
/

so..... where is PKGSELECTCLIENT in your call.

DBMS_SESSION error

Siobhan, December 10, 2004 - 4:18 am UTC

Oops - I changed the call to include the package name and now I get a privileges message:
BEGIN lcid.pkgSelectClient.prcSelectClient('SIOBHAN','01-JAN-1980',1,:c); END;

*
ERROR at line 1:
ORA-01031: insufficient privileges
ORA-06512: at "SYS.DBMS_SESSION", line 78
ORA-06512: at "LCID.PKGSELECTCLIENT", line 17
ORA-06512: at line 1


ERROR:
ORA-24338: statement handle not executed


SP2-0625: Error printing variable "c"

I checked some of your other questions and someone had been getting the same message but I think they had another object with the same name - I definitely do not.
Thanks again
S

Tom Kyte
December 10, 2004 - 10:57 am UTC

did you see your other typo?

pkc vs pkg in the create context.....

you don't have the permission to set the context your package name is wrong.

Ishan Bansal

A reader, December 10, 2004 - 6:13 am UTC


Most helpful!

Siobhan, December 13, 2004 - 5:26 am UTC

Thank you very much - although I do feel like a twit for not seeing the silly mistakes! Sorry to bother you with that! Now I am getting no results but I am sure I can play around with for a while now that its running and get that sorted
Thanks Again


Damn Good

Ramesh, December 17, 2004 - 3:23 am UTC

I see the article is very very usefull.I learnt about Sys_context. I managed to write a package with a procedure similar to the start of the web page.When i execute the package from the SQL Plus its working fine and am able to see the records.But when i call the same procedure of the package from the .NET interface am not empty datatable when am binding to my DataGrid.
If have any idea please help me out.
Many Thanks.

Tom Kyte
December 17, 2004 - 7:59 am UTC

no idea what a ".net interface" is.

or how it could possible affect a stored procedure returning a ref cursor.

Damn Good

Ramesh, December 17, 2004 - 4:58 am UTC

This is follow up for my earlier review.I managed to find the problem. My DataGrid not able to fill with the cursor because for one of the column Orderdate the data type is not matching with Oracle DataType.
Any how i found the article is very very usefull.Thanks again.


Query utilizing Union

Ramesh, December 21, 2004 - 3:07 pm UTC

Hi Tom,
I have a question on using Application Contexts:

1. If I have a query that uses the Union Operator, to return a result set, how can I use Application Context to set the predicate for both the queries? The queries in the Union go against a separate set of tables.Is this a viable option?

declare
l_query varchar2(1000);
l_query1 varchar2(500);
l_query2 varchar2(500);
type rc is REF CURSOR;
l_cursor rc;

begin
-- I set the predicates for l_query1 and l_query2 here
l_query:=l_query1||' union '||l_query2;
open l_cursor for l_query;
fetch
close;

end;





Tom Kyte
December 21, 2004 - 3:22 pm UTC

how "can't" you use an application context in this sense?

I mean, you have a query (forget union, union all, intersect, minus -- whatever) you just have a query.

queries have predicates.

you plop your reference to the application context in the predidate -- done.

DBA_CONTEXT View

Ramesh, December 21, 2004 - 7:03 pm UTC

Hi Tom,
Could you throw some light on this?

I have a package called LOOKUP, and a procedure called OPEN_INVOICE_SEARCH within this package.
I want to set up the context to use this package and procedure.

So,

bis_web @ BIS_DEV>create or replace context MY_CONTEXT using LOOKUP.OPEN_INVOICE_SEARCH;

Context created.

bis_web @ BIS_DEV>select * from dba_context;

NAMESPACE SCHEMA PACKAGE
------------------------------ ------------------------------ ------------------------------
MY_CONTEXT LOOKUP OPEN_INVOICE_SEARCH

bis_web @ BIS_DEV>exec lookup.open_invoice_search('oracle%',null,null,null,null,'abc',86979,null,:x,
'2004');
BEGIN lookup.open_invoice_search('oracle%',null,null,null,null,'abc',86979,null,:x,'2004'); END;

*
ERROR at line 1:
ORA-01031: insufficient privileges
ORA-06512: at "SYS.DBMS_SESSION", line 62
ORA-06512: at "BIS_WEB.LOOKUP", line 759
ORA-06512: at line 1

I get this error while I try to run this procedure within the package.

Now, if I set the context again specifying just the PACKAGE name, then

bis_web @ BIS_DEV>CREATE OR REPLACE CONTEXT MY_CONTEXT USING LOOKUP;

Context created.

bis_web @ BIS_DEV>SELECT * FROM dba_context;

NAMESPACE SCHEMA PACKAGE
------------------------------ ------------------------------ -------------
MY_CONTEXT BIS_WEB LOOKUP

Now, if I run the procedure, I am able to set the context properly and I get the results back.

How I can link a CONTEXT to a particular procedure within a PACKAGE?

Thanks.

Tom Kyte
December 21, 2004 - 7:28 pm UTC

you associate a context with a top level schema object:

o procedure
o package
o function

not a packaged function, not a packaged procedure.


that is the way it works.


create or replace context MY_CONTEXT using
LOOKUP.OPEN_INVOICE_SEARCH;


was looking for a top level schema object owned by someone named LOOKUP

Thanks

Ramesh, December 21, 2004 - 8:54 pm UTC

Hi Tom,
Thanks for the clarification.


Cursor

Vithal, December 22, 2004 - 2:48 am UTC

Hi Tom,

is it posibal to use for loop for ref cursor if yes then how?
and if want to use case statment without using if else and and ref cursot then how can i do? can please help me out.



Thanks
Vithal

Tom Kyte
December 22, 2004 - 9:32 am UTC



open c for ....
loop
fetch c into ....;
exit when c%notfound;
process record
end loop;
close c;


No idea what the case comment was about.

How to user rowid in a ref cursor

Abubaker Khered, December 25, 2004 - 1:57 am UTC

Hi,

I am having a procedure which returns (create_by, create_date) from a particular table based on two parameters which I am passing 1-table name and 2-rowid. But it gives me error whenever I run it, the error is regarding the type and format of the rowid. It works ok when I hard code the rowid.

The procedure is:

CREATE OR REPLACE PROCEDURE PRC_CRE_MDF (i_table in varchar2,
i_rowid in varchar2,
o_cre_by out varchar2,
o_cre_dt out date ) is
type RefType IS ref cursor;
cr_ref RefType;

l_query varchar2(512);
l_cre_by varchar2(30);
l_cre_dt date;

begin
l_query := 'SELECT create_by, create_date FROM '||i_table||
' WHERE rowid = '|| '''i_rowid''' ;
Open cr_ref for l_query;
Fetch cr_ref Into l_cre_by, l_cre_dt ;
IF cr_ref%FOUND THEN
o_cre_by := l_cre_by ;
o_cre_dt := l_cre_dt ;
END IF;
Close cr_ref;
end;

This is the error ORA-01410.
But when I change '''i_rowid''' to 'i_rowid' I recived this error ORA-00904.

Kindly advice on how to solve this problem.

Regards,
Abubaker


Tom Kyte
December 25, 2004 - 9:09 am UTC

BIND VARIABLES he screams at the top of his lungs

bind variables, bind variables, bind variables (just like spam, spam, spam from monty python...)


you gotta BIND, BIND, BIND....



ops$tkyte@ORA9IR2> CREATE OR REPLACE PROCEDURE PRC_CRE_MDF (i_table   in        varchar2,
  2                                           i_rowid   in   varchar2,
  3                                           o_cre_by  out  varchar2,
  4                                           o_cre_dt  out  date     )
  5  is
  6  begin
  7      execute immediate
  8      'select create_by, create_date
  9         from ' || i_table || '
 10       where rowid = :x' into o_cre_by, o_cre_dt using i_rowid;
 11  exception
 12      when no_data_found then NULL; -- you ignored this before
 13                                    -- that is PROBABLY a BUG
 14                                    -- in your logic though, think
 15                                    -- about that.
 16  end;
 17  /
 
Procedure created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> create table t ( create_by varchar2(30), create_date date );
 
Table created.
 
ops$tkyte@ORA9IR2> insert into t values ( user, sysdate );
 
1 row created.
 
ops$tkyte@ORA9IR2> commit;
 
Commit complete.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> declare
  2      l_cre_by varchar2(30);
  3      l_cre_dt date;
  4  begin
  5      for x in ( select rowid rid from t )
  6      loop
  7          prc_cre_mdf( 'T', x.rid, l_cre_by, l_cre_dt );
  8          dbms_output.put_line( l_cre_by || ' ' || l_cre_dt );
  9      end loop;
 10  end;
 11  /
OPS$TKYTE 25-DEC-04
 
PL/SQL procedure successfully completed.
 
 

Thanks, and another question?

Abubaker Khered, December 26, 2004 - 1:47 am UTC

Dear Tom,

Thank you so much for your help.

I have another small question?
In our system we have in some of the tables
(a) create_by
create_date

and in some other tables we go
(b) create_by
create_date
modify_by
modify_date

What is the best way to determined whether this table is (a) or (b) and accordingly returns two or four columns in the above procedure?

Thanks in advance

Regards,
Abubaker


Tom Kyte
December 26, 2004 - 12:39 pm UTC

they invoker should do that -- eg, you PACKAGE these procedures and overload it. the invoker will either call one with 4 outputs, or with 2.


(i actually don't like the premise of this routine, dynamic sql that should be avoided, the invoker should have SELECTED this stuff in the first place)

Thanks

Abubaker Khered, December 27, 2004 - 12:46 am UTC

Thanks

Interval Sum

Vithal, December 29, 2004 - 8:19 am UTC

I had a table as bello
Error_id Error_no Err_Date
1 12 12-dec-2004 12:30 PM
2 11 12-dec-2004 12:32 PM
3 22 12-dec-2004 12:39 PM
4 3 12-dec-2004 12:42 PM
5 45 12-dec-2004 12:45 PM
6 6 12-dec-2004 12:50 PM
7 78 12-dec-2004 12:51 PM
8 8 12-dec-2004 12:54 PM
9 45 12-dec-2004 12:56 PM
10 4 12-dec-2004 12:59 PM

I want the sum of the errors for every 20 min interval
like

start time end time errors
12:20 12:40 ?
12:40 13:00 ?
can u please guide on this..


Tom Kyte
December 29, 2004 - 10:24 am UTC

you just need to take your DATE field and make it conform to 20 minute intervals.

so xx:00:00 .. xx:19:59 => xx:00:00
   xx:20:00 .. xx:39:59 => xx:20:00
   xx:40:00 .. xx:59:59 => xx:40:00


we can do that with simple division:

ops$tkyte@ORA9IR2> select r, int
  2    from (
  3  select r, int,
  4         lag(int) over (order by r) last_int,
  5             lead(int) over (order by r) next_int
  6    from (
  7  select rownum r, trunc(rownum/20) int
  8    from all_objects
  9   where rownum <= 60
 10         )
 11         )
 12   where int <> last_int or int <> next_int
 13  /
 
         R        INT
---------- ----------
        19          0
        20          1
        39          1
        40          2
        59          2
        60          3
 
6 rows selected.
 


r's 1..19 => 0
   20..39 => 1
   40..59 => 2


so:

ops$tkyte@ORA9IR2> select dt,
  2         trunc(dt,'hh') + (trunc(to_char(dt,'mi')/20) * 20)/24/60 newdt
  3    from (
  4  select trunc(sysdate,'hh')+(rownum-1)/24/60 dt
  5    from all_objects
  6   where rownum <= 60
  7         )
  8  /
 
DT                   NEWDT
-------------------- --------------------
29-dec-2004 10:00:00 29-dec-2004 10:00:00
...
29-dec-2004 10:19:00 29-dec-2004 10:00:00
29-dec-2004 10:20:00 29-dec-2004 10:20:00
...
29-dec-2004 10:38:00 29-dec-2004 10:20:00
29-dec-2004 10:39:00 29-dec-2004 10:20:00
29-dec-2004 10:40:00 29-dec-2004 10:40:00
...
29-dec-2004 10:59:00 29-dec-2004 10:40:00
 
60 rows selected.



You would select newdt (as a function of err_date) and group by that. 

ORA-08103

Vithal, December 30, 2004 - 5:22 am UTC

Hi Tom,

I am creating a table using select from other tables.

but after an 1 hour I got the error ORA-08103: object no longer exists But the table is exists in the database.. then why this error came in this kind of situation. the table contain 1,000,000,000 data.

can you please guide on this...


Tom Kyte
December 30, 2004 - 10:49 am UTC

the 8103 most likely means one of the tables you were querying had DDL applied to it (like an alter table exchange partition, truncate partition, truncate table, drop table)...

the query will run fine -- as long as the space occupied by the dropped/truncated/altered object is not reused.

if it gets reused -- then the old data is wiped out and you get "object no longer exists"


so, any chance -- any chance at all that the objects you were QUERYING were being worked on by someone else.

Interval Sum

A reader, December 30, 2004 - 9:11 am UTC

Hi Tom,

Still not clear can u please give me another example.



Tom Kyte
December 30, 2004 - 11:05 am UTC

kidding right?

I showed a function to take any date/time as input and return a date time rounded to the 00, 20, 40 minute interval.

group by it.


select f(date_column), sum(whatever)
from any_table
group by f(date_column)

wah-lah -- data aggregated to the intervals 00, 20, 40?


select trunc(dt,'hh') + (trunc(to_char(dt,'mi')/20) * 20)/24/60,
<YOUR AGGREGATES>
from t
group by trunc(dt,'hh') + (trunc(to_char(dt,'mi')/20) * 20)/24/60

transpose in SQL

Vithal, January 05, 2005 - 5:16 am UTC

Hi Tom,

If i want to show the rows in columns like

Empno
--------
7722
1234
4432
1234
2334
1234

with

EMP EMP1 EMP2 EMP3 EMP4 EMP5 EMP6
------------------------------------
EMPNO 7722 1234 4432 1234 2334 1234


Can u please guide on this




Tom Kyte
January 05, 2005 - 9:53 am UTC

search this site for

pivot

Viable Alternative?

Kyle, January 27, 2005 - 6:04 pm UTC

Tom:

Is this a viable alternative to using an application context? I have commented the changes to your example...

create or replace
procedure my_procedure( p_ename in varchar2 default NULL,
p_hiredate in date default NULL,
p_sal in number default NULL)
as
type rc is REF CURSOR;

l_cursor rc;
l_query varchar2(512)
default 'select * from emp where 1 = 1 ';

cursor l_template is select * from emp;
l_rec l_template%rowtype;

-- initialize an array of varchar2 to hold the
-- dymanic variable values
type var_array is varray(3) of varchar2(25);
varr var_array := var_array();
i integer;

begin

if ( p_ename is NOT NULL ) then
-- extend the array, add the variable's value and
-- append to the query string
varr.EXTEND;
varr(varr.LAST) := '%'||upper(p_ename)||'%';
l_query := l_query ||
' and ename like :x';
end if;

if ( p_hiredate is NOT NULL ) then
varr.EXTEND;
varr(varr.LAST) := to_char(p_hiredate,'yyyymmddhh24miss');
l_query := l_query ||
' and hiredate > to_date(:x, ''yyyymmddhh24miss'') ';
end if;

if ( p_sal is NOT NULL ) then
varr.EXTEND;
varr(varr.LAST) := to_char(p_sal);
l_query := l_query ||
' and sal > to_number(:x) ';
end if;

-- loop through the remaining array elements and initialize them
-- append to the query string
for i in (nvl(varr.last, 0) + 1)..varr.limit loop
varr.extend;
varr(varr.last) := 'X';
l_query := l_query || ' AND :x = ''X''';
end loop;

p( l_query );

-- execute the query using the array elements
open l_cursor for l_query USING varr(1), varr(2), varr(3);

loop
fetch l_cursor into l_rec;
exit when l_cursor%notfound;

dbms_output.put_line( l_rec.ename || ',' ||
l_rec.hiredate || ',' ||
l_rec.sal );
end loop;

close l_cursor;
end;


It works, and is using bind variables, but I'm concerned about optimization being affected by adding "AND :x = 'X'" multiple times in the WHERE clause? I'm thinking its ok, since 1 = 1 gets optimized away.

Thank you for your time! It is much appreciated! I always learn from your examples.

Kyle


Tom Kyte
January 28, 2005 - 7:14 am UTC

ctl-f for "Darko" on this page.

that would be a cleaner way to do this, no array needed.

Viable Alternative

Kyle, January 28, 2005 - 9:46 am UTC

Tom:

Ahhh, how did I miss that? So something like this?

CREATE OR REPLACE
procedure my_procedure2( p_ename in varchar2 default NULL,
p_hiredate in date default NULL,
p_sal in number default NULL)
as
type rc is REF CURSOR;

l_cursor rc;
l_query varchar2(512)
default 'select * from emp where 1 = 1 ';

cursor l_template is select * from emp;
l_rec l_template%rowtype;

c_p_ename varchar2(25) default null;
c_p_hiredate varchar2(25) default null;
c_p_sal varchar2(25) default null;
begin

if ( p_ename is NOT NULL ) then
c_p_ename := '%' || upper(p_ename) || '%';
l_query := l_query ||
' and ename like :x';
else
l_query := l_query ||
' and :x is null';
end if;

if ( p_hiredate is NOT NULL ) then
c_p_hiredate := to_char(p_hiredate,'yyyymmddhh24miss');
l_query := l_query ||
' and hiredate > to_date(:x, ''yyyymmddhh24miss'') ';
else
l_query := l_query ||
' and :x is null';
end if;

if ( p_sal is NOT NULL ) then
c_p_sal := to_char(p_sal);
l_query := l_query ||
' and sal > to_number(:x) ';
else
l_query := l_query ||
' and :x is null';
end if;

p( l_query );

open l_cursor for l_query USING c_p_ename, c_p_hiredate, c_p_sal;

loop
fetch l_cursor into l_rec;
exit when l_cursor%notfound;

dbms_output.put_line( l_rec.ename || ',' ||
l_rec.hiredate || ',' ||
l_rec.sal );
end loop;

close l_cursor;
end;
/


Thanks again,

Kyle


Tom Kyte
January 28, 2005 - 2:27 pm UTC

if ( p_hiredate is NOT NULL ) then
c_p_hiredate := to_char(p_hiredate,'yyyymmddhh24miss');
l_query := l_query ||
' and hiredate > to_date(:x, ''yyyymmddhh24miss'') ';
else
l_query := l_query ||
' and :x is null';
end if;

would just be:

if ( p_hiredate is NOT NULL ) then
l_query := l_query ||
' and hiredate > :x ';
else
l_query := l_query ||
' and :x is null ';
end if;

and same with the "to_number", you would be BINDING a date, binding a number -- no conversion needed or desired.

using '%'||upper(p_ename)||'%', p_hiredate, p_sal;




Viable Alternative

Kyle, January 28, 2005 - 9:54 am UTC

Tom:

Sorry to immediately reply to my own post, but one thing I just realized is that in my last example, you must have a fixed number of bind variables. When using an application context or the array example I provided previously, you do not have this constraint.

Kyle


Tom Kyte
January 28, 2005 - 2:27 pm UTC

you do have a fixed MAX number of binds, that is all you need (and you always have that... a MAXIMUM, else you would not know how many IF's to code)

Viable Alternative

Kyle, January 31, 2005 - 3:42 pm UTC

Hi Tom:

For clarification, in the followup you provided before, I don't think passing '%'||upper(p_ename)||'%' in the open..using statement will work properly. Wouldn't it evaluate to '%%' when p_ename is NULL, which would be false when checking if the variable is null in the query string? Wouldn't the proper method be to pass the variable p_ename in the open..using statement and use the following to build the query string:

if ( p_ename is NOT NULL ) then
l_query := l_query ||
' and ename like ''%'' || upper(:x) || ''%''';
else
l_query := l_query ||
' and :x is null';
end if;

Thanks again,

Kyle

Tom Kyte
January 31, 2005 - 4:04 pm UTC

yup, good point.



Great discussion

Martin, February 03, 2005 - 3:17 am UTC

This is a great discussion thread, however, I've recently been looking into the possibility of tuning some of our SQL by utilising scalar subquery caching, and while i've had great success when dealing with PL/SQL function calls etc, I thought i'd look into maybe applying the same techniques to certain
SQL function calls (such as user, sysdate etc).

However, these type of function calls perform significantly worse when using a dual-subquery type approach, which I assume means that they're already cached for us?

Can you quickly outline the rules behind what types of function calls *may* benefit from subquery caching? And, is there a document somewhere which describes it in more detail?

Thanks in advance

Tom Kyte
February 03, 2005 - 1:27 pm UTC

user, sysdate, etc are semi-bind variables.

select to_char(sysdate,'sssss') from one_billion_row_table_that_takes_30_seconds_to_scan;

will return a constant value.


PLSQL called from SQL can benefit from this


select a, f(a) from t;

can benefit from

select a, (select f(a) from dual) from t;

and even more so perhaps (if the sort is less work than the f(a) call)

select a, (select f(a) from dual) from (select a from t order by a);


that will call f once typically for each distinct value of A, so if A has 100 distinct values, but T has 100,000 rows -- you might find sorting and then calling is better.

Cursors

JOJEDA, February 03, 2005 - 2:41 pm UTC

Tom, I need to create a package with refcursors to store the sql stmt and get the resultset on the client, do you have a better way to to do that??

CREATE OR REPLACE PACKAGE BNFTEST.PKG_RC
AS
TYPE RC IS REF CURSOR;
c1 varchar2(255) default 'select sysdate from dual';
c2 varchar2(255) default 'select user from dual';
PROCEDURE SP_RC(p_refcur OUT PKG_RC.RC, p_rc in number);
END PKG_RC;
/

CREATE OR REPLACE PACKAGE BODY BNFTEST.PKG_RC is
PROCEDURE SP_RC(p_refcur OUT PKG_RC.RC, p_rc in number)
IS
BEGIN
CASE
WHEN p_rc=1 THEN
OPEN p_refcur FOR c1;
WHEN p_rc=2 THEN
OPEN p_refcur FOR c2;
END CASE;
END SP_RC;
END PKG_RC;
/

Thanks,

Tom Kyte
February 04, 2005 - 1:22 am UTC

CREATE OR REPLACE PACKAGE BNFTEST.PKG_RC
AS
TYPE RC IS REF CURSOR;
PROCEDURE SP_RC(p_refcur OUT PKG_RC.RC, p_rc in number);
END PKG_RC;
/

CREATE OR REPLACE PACKAGE BODY BNFTEST.PKG_RC is
PROCEDURE SP_RC(p_refcur OUT PKG_RC.RC, p_rc in number)
IS
BEGIN
CASE
WHEN p_rc=1 THEN
OPEN p_refcur FOR select sysdate from dual;
WHEN p_rc=2 THEN
OPEN p_refcur FOR select user from dual;
END CASE;
END SP_RC;
END PKG_RC;
/



never ever ever use dynamic sql when static sql will do. never.

input/output in compile-time

Harp, February 23, 2005 - 6:48 am UTC

Hi Tom!
I just used some of the examples you gave about cursor which helped me much. One thing I would like to know is this:
is there anyway I can know whether the parameters of a stored procedure is an input, output or input_output after preparing the sql-statement but before executing the statement (via odbc). If you have an example, I would appreciate it too.

Thanks
Harp




Tom Kyte
February 23, 2005 - 9:20 am UTC

I don't program ODBC at all but

ALL_ARGUMENTS (dictionary view) contains that as well dbms_describe.describe_procedure will work.

Where are package global variables and types stored?

Andrew, March 03, 2005 - 5:33 pm UTC

Just following up on your ALL_ARGUMENTS comment, I cannot find anywhere in any Oracle documentation: where can I get all the global variables, constants, and types for a given package, besides parsing user_source? Surely there must be a data_dictionary view that the compiler & debugger uses?

Also, are there JDBC metadata classes that are equivalent to ALL_PROCEDURES and ALL_ARGUMENTS?

Tom Kyte
March 03, 2005 - 5:46 pm UTC

surely ? why surely?

no, there is not, they are not exposed in a dictionary views.


I don't know if there are jdbc metadata classes or not.

how to solve the problem in a 9i rac env&#65311;

'.......', March 04, 2005 - 9:00 am UTC

hello ,tom
This is very helpful!but can we use the sys_context function in a 9i RAC environment
to bind variables like this?if can't, then how to return the ref cursor based on each non-ull parameter with variables binded? help me out:
if a is not null then
vsql := vsql || ' and col1=:bind_a';
end if;
...
if a is not null and b is null then
open vref_cursor for vsql using a;
end if;
if a is null and b is not null then
open vref_cursor for vsql using b;
end if;
if a is not null and b is not null then
open vref_cursor for vsql using a,b;
end if;
...
return vref_cursor;

--------------------------------------
if the inputs passed in are a, b,c,d , e...and ...?
Thanks

with regards,

'.......'


Tom Kyte
March 04, 2005 - 9:34 am UTC

sure you can -- rac won't affect this.

or ctl-f for " a non dynamic alternative " if you don't want to use them.

help in a 9irac env

'............', March 04, 2005 - 10:14 am UTC

thanks ,tom
but there is a note in the Oracle9i SQL Reference( Part Number A96540-01) document:
SYS_CONTEXT returns session attributes. Therefore, you cannot use it in parallel queries or in a Real Application Clusters environment. and i am confused and worrying about my pl/sql code won't work well when the database use a rac envionment.
here is the url:</code> http://www.lc.leidenuniv.nl/awcourse/oracle/server.920/a96540/functions122a.htm#1038178 <code>



Tom Kyte
March 04, 2005 - 11:02 am UTC

govindarajn, March 31, 2005 - 3:01 am UTC

can i transfer the tables from one user to another

ie the user A having 10 tables and user B having 0 tables.now i want TO copy all the tables to user .
WITHOUT EXPORT/IMPORT UTILITY IS IT POSSIBLE TO COPY A TABLES FROM ONE USER TO ANOTHER?

Tom Kyte
March 31, 2005 - 7:40 am UTC

connect b
create table my_copy_of_a_table as select * from a.table_name;

do that for each table.

Do it on the application side

A reader, March 31, 2005 - 2:07 pm UTC

On the orignal post of a gerneric sql engine: if using a java app server, would it not be a simple solution build the query on the java side which make the conncationation of ?, ?, ? and bind varables very easy. I do know your view on having SQL on the app server, but it seems it would make the code simplier and eaiser to read. Performace should be the same, or quicker since there is no "context" component.

Tom Kyte
March 31, 2005 - 3:08 pm UTC

but a context is a bind, and I'd rather have the SQL in the server -- where I can find it, fix it, tune it, correct it.

Also, I can reuse this routine all over the place, by any language/environment

And I don't have to convince the java coders that binding in SQL is important ;) Still gotta get them to call the routine with binds, but that is easier than telling them they have to bind the dynamically constructed SQL.

Besides, the original poster might have wanted another plsql routine to have been the recipient.

Do it on the application side

A reader, April 01, 2005 - 1:51 pm UTC

How about a java stored procedure?

Tom Kyte
April 01, 2005 - 1:55 pm UTC

why? you are in the database, working with data. there is no language better for doing SQL in Oracle than plsql.

How to Extend this technique to Joining multiple Tables

A reader, April 11, 2005 - 11:15 am UTC

Tom,

This thread has great relevance to building search procedures for web applications. A generic search in our application involves variable number of paramaters spanning multiple tables. Depending on what parameters are set, I may need to join different set of tables. Following is an illustrative example of a search function's signature:

CREATE OR REPLACE PACKAGE equipment
AS

FUNCTION equipment_details (
equipment_id_in equipments.equipment_id%TYPE DEFAULT NULL
,equipment_industry_in equipements.equipment_industry%TYPE DEFAULT NULL
,equipmment_owner_id_in equipment_owners.equipment_owner_id%TYPE DEFAULT NULL
,equipment_dealer_id_in equipment_owner.dealer_id%TYPE DEFAULT NULL
,eqp_dealer_account_id_in eqp_owner_dealer_csutomers.dealer_account_id_in DEFAULT NULL
:
:
:

)
RETURN config.RefCursorTyp;


END equipment;


Typically, some of these paramters result in one or more predicates against one table. I can use SYS_CONTEXT to add adequate predicates against one table. Do you have an example (illustrating a generic approach to this situation)where I can also vary the table list and join predicates besides predicates filtering rows of a table?

The three approaches we have used so far are:

1. If then else logic to assemble a custom (dynamic) query in response to each permutation of the input paramaters. I find this approach somewhat difficult to maintain and extend. The code quickly gets unwildy with each additional search condition added leading to ever more permutations and somewhat tricky debugging as each possible search path now needing to be retested.

2. If then else logic to attach a specific predetermined query to the result set specific query (in some situations you can end up with 3-4 dozen pre-set permutations (queries)).

3. Join all the underlying tables (default query) and add table filtering perdicates (projections) depending on the parameters. While it is easier to maintain and extend, I am sure joining all 10 tables in response to every situation is not a a great idea. In most situations only a sub-set of tables should be joined.

Any examples or inputs would be greatly appreaciated.

Tom Kyte
April 11, 2005 - 11:20 am UTC

you would vary the table list? Seems if you SELECT a column from a table, you would either

a) always select that column
b) never select that column

regardless of the predicates?

I can see adding predicates that are SUBQUERIES, but I cannot envision where the predicates would drive the set of tables in the from clause for a search?


select * from emp; -- no predicates.

select * from emp where job = sys_context() -- filter on job

select * from emp where job = sys_context()
and deptno in (select deptno from dept where dname = sys_context() ) -- filter on job and departement name

and so on...



A reader, April 20, 2005 - 4:46 pm UTC

Could you please give an example of refcursor/context object with BULK COLLECT?
When I bulk collect into a collectin; I am getting more records than that are returned by the query (based on which ref cursor is opened).

Thanks in advance.

Tom Kyte
April 20, 2005 - 9:15 pm UTC

how about you give me the example that fails....

A reader, April 20, 2005 - 5:06 pm UTC

I have following collections at SQL level:
create or replace rec as object
(
job varchar2(20),
hdate date
);

create or replace type emp_tab
as varray of rec(10);

-----------------

I have package like this, (i have not included package specififcation here):


create or replace package body pack1
is
type job_type is table of emp.job%type index by binary_integer;
type date_type is table of emp.hiredate%type index by binary_integer;

procedure p1( i_name in emp.ename%type,
i_sal in emp.sal%type,
o_rec out emp_tab
)
as

l_qry varchar2(4000) 'select job,hiredate from emp';

v_job job_type;
v_date date_type;

c1 ref cursor;

begin

DBMS_SESSION.set_context ('dctx1', 'name', (i_name));
l_qry := l_qry || ' and ename = sys_context( ''dctx1'', ''name'' ) ';


open c1 for l_qry;

fetch c1 bulk collect into v_job,v_date;

o_rec := emp_tab(rec(null,null));

for i in v_job.first .. v_job.last
loop
o_rec.extend;
o_rec(i):= rec(v_job(i),v_date(i));
end loop;

end p1;

end pack1;


Problem:
I have captured l_qry and it is giving correct result. But, when i bulk collect into collection it is fetching more records (duplicates). What am I doing wrong?

Please Help.

Tom Kyte
April 20, 2005 - 9:17 pm UTC

give entire example from start to finish, that I can cut and paste and run

(and why not just

select rec( job, hiredate ) bulk collect into rec from emp where ....

and be done with it?

A reader, April 21, 2005 - 8:22 am UTC

Thanks for your response! But when I said

select rec(job,date) into rec from ...

i am not getting any data, no records are fetched.

please help.

Tom Kyte
April 21, 2005 - 11:53 am UTC

*give ENTIRE example*

something i can cut and paste and run

small, concise, yet 100% complete.

A reader, April 21, 2005 - 12:47 pm UTC

At SQL level:
------------------
create or replace rec as object
(
job varchar2(20),
hdate date
);

create or replace type emp_tab
as varray of rec(10);

--------------------------------------


create or replace package pack1
is

type cur is ref cursor;

procedure p1( i_name in emp.ename%type,
i_sal in emp.sal%type,
o_rec out emp_tab
);
end pack1;

-----------------------


create or replace package body pack1
is
type job_type is table of emp.job%type index by binary_integer;
type date_type is table of emp.hiredate%type index by binary_integer;

procedure p1( i_name in emp.ename%type,
i_sal in emp.sal%type,
o_rec out emp_tab
)
as
--***as per your suggestion; i am bulk collecting here, but records are not retrieved
l_qry varchar2(4000) 'select rec(job,hiredate) into o_rec from emp';

v_job job_type;
v_date date_type;

c1 cur;

begin

if i_name is not null then
DBMS_SESSION.set_context ('dctx1', 'name', (i_name));
l_qry := l_qry || ' and ename = sys_context( ''dctx1'', ''name'' ) ';
end if;

/*
----------- l_qry has right output
open c1 for l_qry;

----***here i am getting duplicates
fetch c1 bulk collect into v_job,v_date;

o_rec := emp_tab(rec(null,null));

for i in v_job.first .. v_job.last
loop
o_rec.extend;
o_rec(i):= rec(v_job(i),v_date(i));
end loop;
*/


end p1;

end pack1;



Tom Kyte
April 22, 2005 - 9:12 am UTC

you do realize that NONE of your statements actually "run" in sqlplus right?  missing create context, the varray define is wrong, the package is not "doing anything"

An example would be "here, run this as scott/tiger and it'll show you this"

as it is, I'm not really sure "what" we are supposed to be looking for.


Now, if you code the package body like this:

ops$tkyte@ORA9IR2> create or replace package body pack1
  2  is
  3  type job_type is table of emp.job%type index by binary_integer;
  4  type date_type is table of emp.hiredate%type index by binary_integer;
  5
  6  procedure p1( i_name  in  emp.ename%type,
  7                i_sal   in  emp.sal%type,
  8                o_rec   out emp_tab
  9          )
 10  as
 11     v_job job_type;
 12     v_date date_type;
 13     c1 cur;
 14     l_qry varchar2(4000) := 'select job, hiredate from emp where 1=1 ';
 15  begin
 16   if i_name is not null then
 17     DBMS_SESSION.set_context ('dctx1', 'name',  (i_name));
 18     l_qry := l_qry || ' and ename = sys_context( ''dctx1'', ''name'' ) ';
 19   end if;
 20
 21   open c1 for l_qry;
 22
 23    fetch c1 bulk collect into v_job,v_date;
 24    for i in 1 .. v_job.count
 25    loop
 26       dbms_output.put_line( v_job(i) || ', ' || v_date(i) );
 27    end loop;
 28  end p1;
 29
 30  end pack1;
 31  /
 
Package body created.
 
ops$tkyte@ORA9IR2> show err
No errors.
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> declare
  2     x emp_tab;
  3  begin
  4      pack1.p1( 'KING', null, x );
  5  end;
  6  /
PRESIDENT, 17-NOV-81
 
PL/SQL procedure successfully completed.


there are no duplicates (if you believe you are getting them, you will ned to supply a 100% complete, yet concise/small testcase that ANYONE can run from start to finish)


but you don't need all of those little tables:


ops$tkyte@ORA9IR2> create or replace package body pack1
  2  is
  3
  4  procedure p1( i_name  in  emp.ename%type,
  5                i_sal   in  emp.sal%type,
  6                o_rec   out emp_tab
  7          )
  8  as
  9     l_qry varchar2(4000) := 'select rec(job, hiredate) from emp where 1=1 ';
 10  begin
 11   if i_name is not null then
 12     DBMS_SESSION.set_context ('dctx1', 'name',  (i_name));
 13     l_qry := l_qry || ' and ename = sys_context( ''dctx1'', ''name'' ) ';
 14   end if;
 15
 16   execute immediate l_qry bulk collect into o_rec;
 17   for i in 1 .. o_rec.count
 18   loop
 19      dbms_output.put_line( o_rec(i).job || ', ' || o_rec(i).hdate );
 20   end loop;
 21  end p1;
 22
 23  end pack1;
 24  /
 
Package body created.
 
ops$tkyte@ORA9IR2> show err
No errors.
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> declare
  2     x emp_tab;
  3  begin
  4      pack1.p1( 'KING', null, x );
  5  end;
  6  /
PRESIDENT, 17-NOV-81
 
PL/SQL procedure successfully completed.
 

A reader, April 22, 2005 - 9:33 am UTC

Thanks a lot for your example.

I did the way you suggested:
execute immediate l_qry bulk collect into o_rec;

This is the error I am getting:
ORA-00932: inconsistent datatypes: expected UDT got CHAR


Thanks in advance!

Tom Kyte
April 22, 2005 - 10:45 am UTC

example or I just ignore it.

I gave you one -- that with your creates and such (once fixed) runs. from start to finish.

you have to give me one from start to finish that doesn't run (and be AS SMALL AS POSSIBLE)

XYZ

A reader, April 22, 2005 - 11:01 am UTC

How can I clear the values assigned to Session Context?

The reason I am asking this is if I don't use Session Context I am getting correct results, with it I am getting incorrect output.

Thanks in advance!

Tom Kyte
April 22, 2005 - 11:10 am UTC

provide EXAMPLE

with or without a context set, should not matter -- the results are "deterministic" as they say.

grant privilege for alter trigger

Ronald Chan, April 27, 2005 - 5:11 am UTC

It is possible to grant just alter trigger privilege to other users?
so that alter trigger is the only action this user can do.

Tom Kyte
April 27, 2005 - 8:05 am UTC

</code> https://www.oracle.com/technetwork/issue-archive/2005/05-jan/o15asktom-084959.html <code>

see the last part of that page -- it is about selectively granting alter system on user_dump_dest, but the same technique applies.

Alex, May 05, 2005 - 11:46 am UTC

Tom,

Just curious, why does Oracle allow you to select..into in a cursor or ref cursor? It's not really correct to do that right? Does Oracle just ignore nonsense like this?

I've come across other nonsensical code in our app that apparently Oracle pays no attention to such as

select...from..where col1 is null or col1 is not null.



Tom Kyte
May 05, 2005 - 12:59 pm UTC

well, you can select CURSOR( select ...) from table, so the semantics are there for doing so, yes.

connection pool and SYS_CONTEXT

reader, May 23, 2005 - 2:25 pm UTC

Is it advisable to use SYS_CONTEXT in connections pool environment? Just a dump question, as we are using the connection pools from websphere in high transactions OLTP system.

Thanks,

Tom Kyte
May 23, 2005 - 7:07 pm UTC

as long as you explicity set the context values before using them and be aware that they could contain legacy values from prior "sessions"

What is the impact on session cache

reader, May 25, 2005 - 11:24 am UTC

Thanks, I was looking for some Oracle document how the sys context internally behaving but could not find the detail one.

We have one query in stored procedure (person search) that is executed 3000 times a day by call center users. The user application is in Java and application server using connection pooling.

The "Where" conditions are different each time, so developer built the dynamic query to accept different conditions. We found around 5000 different versions in sqlarea. Sometimes performance is also not good with this query. So we decided to tune this without changing business logic by binding all variables in this query (around 21 different variables) using sys_context.

Now the question is what is the tradeoff between allowing hard parse every time verses setting sys_context. Is the query going to perform slow because there must be some overhead to set the sys context in the memory?

What it is the impact on the session memory when we set these many contexts? Do we need any special setting to avoid any memory issue due to this? We are using session_cache_cursor =100. Oracle 9.2.0.6 on sun Solaris, 8 cpus with 24GB memory just for one database instance. I am sorry for asking so many questions but our system in production and we do not have good handle on the sys context yet.


Tom Kyte
May 25, 2005 - 1:59 pm UTC

sys_context is treated as a bind variable (but no bind variable peeking)

I would not have "a single query" but rather -- N queries - using this technique:
</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:1288401763279 <code>

that way, each individual query is eminently shareable, but also optimized to the question at hand.

Lora, May 25, 2005 - 6:05 pm UTC

Hello Tom,

Can you please comment on this approach?
It seems to me that the indexes will be used…

....

select *
from emp e
where (b_ename is null or e.ename = b_ename)
and (b_hiredate is null or e.hiredate = b_hiredate)
and (b_sal is null or e.sal = b_sal);

...

Thanks!
Lora

Tom Kyte
May 25, 2005 - 8:06 pm UTC

no, they won't be. I would (do) use the approach above.

deepak, May 26, 2005 - 3:45 am UTC

Just a query on similar line. When we submit a query oracle checks whether cusor is opened or not. Now I am not getting how oracle find out whether a cursor is open or not.

Genral flow is like ..
-------------------------------------------
Statement
Submitted
|
Is it in an open cursor?--------------YES----V
| |
NO |
| |
Is SESSION_CACHED_CURSORS = Value |
and cursor in --------------YES----V In these 3 cases we
Session Cursor cache? | know that the cursor has
| | already been parsed, so
NO | re-parsing is
| | unnecessary.
Is HOLD_CURSOR=Y |
and cursor in --------------YES----V
Held cursor cache? |
| |
NO |
| | ^
OPEN A CURSOR | CLIENT SIDE |
| | -------------|
Statement is Hashed and compared | SERVER SIDE |
with the Hashed value in the sql area | V
| V
Is it in sql area? --YES-(Soft Parse)--> ---------
| | |
NO | EXECUTE |
| | |
PARSE STATEMENT ('Hard' Parse)---------> ---------
is...
-------------------------------------------
Can you please tell me how oracle find out whether cursor is open or not.

Tom Kyte
May 26, 2005 - 8:46 am UTC

well, really the DEVELOPER does "step one"

if (statement is not parsed)
then
ask oracle to parse it
end if;

some environments like PLSQL, cache the cursors for us -- they have this logic in their implementation.

jdbc 3.0 can do this -- when you say "prepare statement", they first look in a client cache for the query.

So, this is a developer thing, not a server thing really.

CURSOR and dynamic sql

Michael Nelson, May 26, 2005 - 6:42 pm UTC

Instead of calling sys_context. What if you did the following. I believe that it still uses the bind variables the way you explain eariler. This allows for null or a value to be passed.

CREATE OR REPLACE PACKAGE BODY ALL_PRODS
AS

function my_procedure(P_sal IN NUMBER DEFAULT NULL,
p_hiredate_num in date default null,
p_ename in varchar2 default null)
return MASTER_PROD.m_prod_TAB PIPELINED
IS

TYPE REF_CUR IS REF CURSOR;
L_CURSOR REF_CUR;


L_QUERY VARCHAR2(2000) DEFAULT 'SELECT PRODUCT_ID, NAME, SUPPLIER_NUM FROM prod_1
where ((p_sal is null) or (p_sal = sal))';
and ((p_ename is null) or (p_ename = name))';
and ((p_date is null) or (p_date= emp_date))';

L_PROD_X MASTER_PROD.M_PROD;

BEGIN
OPEN L_CURSOR FOR L_QUERY;
LOOP
FETCH L_CURSOR INTO L_PROD_X.PRODUCT_ID, L_PROD_X.NAME, L_PROD_X.SUPPLIER_NUM;
DBMS_OUTPUT.PUT_LINE(L_QUERY);
PIPE ROW (L_PROD_X);
...
...

Tom Kyte
May 26, 2005 - 7:47 pm UTC

the goal:

have the best query for the inputs provided


the only way to accomplish that:

build a predicate that makes sense.


the optimizer, given:

where ((p_sal is null) or (p_sal = sal))';
and ((p_ename is null) or (p_ename = name))';
and ((p_date is null) or (p_date= emp_date))';

is going to pick -- probably NO indexes here (it could pick one, but which one? the one when p_sal is not null is wrong when p_sal is null and p_ename isn't)

you want to have predicates that represent what you are searching for

where x = :x
where y = :y
where z = :z
where x = :x and y = :y
where x = :x and z = :z
where y = :y and z = :z
where x = :x and y = :y and z = :z

so the optimizer can develop the plan that is right for each.

Using Cursor

Kamal, May 31, 2005 - 10:51 am UTC

Hi Tom,

We are using a code where the SQL is stored in a table, we need to retrieve the SQL and then open a Cursor for that SQL. The Problem is we were not able to declare a Record for that cursor as it is fetched dynamically. How to declare a record such type of Ref cursor?

I tried this way using Cursor FOR Loop(as it automatically declare the record type)

declare
str_sql varchar2(2000) := 'select empno from emp';

begin

for rec_emp in (str_sql) loop
dbms_output.put_line('Empno :' || Empno);
End loop;

End;

But still it is throwing error...can you throw some light on this issue.

Thanks
kamal

Tom Kyte
May 31, 2005 - 6:30 pm UTC

you need to use dbms_sql for this, dbms_sql provides "api" based access to the columns.

You will not be using native dynamic sql for this, since you quite simply don't know at compile time how many columns, what their types are or anything.

DBMS_SQL is going to be what you need.

</code> http://asktom.oracle.com/~tkyte/flat/index.html <code>
has examples of plsql dumping any query to a flat file for example

nina, July 17, 2005 - 11:43 pm UTC

Tom --

I am trying to create a dynamic where clause based on this example. I have the following procedure that takes in several parms, which can potentially be NULL. So, the proc looks like this:

v_inc_ecls_p comes in as a string, that can look like this, for example:


and ( pebempl_ecls_code like ('AM') or pebempl_ecls_code like ('AS') or pebempl_ecls_code like ('S%') or pebempl_ecls_code like ('S%'))

So here is the proc:

PROCEDURE p_main_process_1
(v_one_n IN VARCHAR2,
v_inc_ecls_p IN VARCHAR2 default NULL)
IS
TYPE rc IS REF CURSOR;
l_cursor rc;
l_query VARCHAR2(4000)
DEFAULT 'SELECT spriden_id,
SUBSTR(spriden_last_name,
1,
20) last_name,
pebempl_ecls_code
FROM spriden, pebempl
WHERE spriden_pidm = pebempl_pidm
ORDER BY spriden_pidm';

CURSOR l_template IS SELECT spriden_id, spriden_last_name,
pebempl_ecls_code
FROM spriden, pebempl;
l_rec l_template%ROWTYPE;

BEGIN



IF ( v_inc_ecls_p is NOT NULL ) THEN
dbms_session.set_context( 'EMP_CTX', 'ENAME',
'%'||v_inc_ecls_p||'%');
l_query := l_query ||
' sys_context( ''EMP_CTX'', ''v_inc_ecls_p'' ) ';
END IF;

OPEN l_cursor FOR l_query;
LOOP
FETCH l_cursor INTO l_rec;
EXIT WHEN l_cursor%NOTFOUND;

INSERT INTO test_tbl (COL1, COL2)
VALUES(l_rec.spriden_pidm,l_rec.pebempl_ecls_code);


END LOOP;

CLOSE l_cursor;

COMMIT;
end p_main_process_1;


when I pass NULL to v_inc_ecls_p, it works fine, but when I try to pass that long string from the example above, I get ORA-00933 SQL Command not properly ended ...it shows that the error is here:

l_query := l_query ||
' sys_context( ''EMP_CTX'', ''v_inc_ecls_p'' ) ';
END IF;


I have no idea where. The thing is that v_inc_ecls_p might come in as a very long string as above, or as NULL or maybe a short string..Can I use the example shown here, or do I need to do something else...Please, advise..


Tom Kyte
July 18, 2005 - 7:53 am UTC

just print out the query - and when you see it, you'll see "why"


select * from t where sys_context( 'x', 'y', 'z' );


that query is not sensible (hopefully you agree). That is the form of query however you are constructing.

in your case, if it is really a bunch of "or'ed likes" like that you will have a really hard time making shareable sql.

Context vs Alternate way

A reader, July 21, 2005 - 5:15 pm UTC

Tom,
I have read your response to a question posed by Darko (ctrl-f darko), "why not alternate way" and you said why to add an extra decode . Well if my requirement is if that variable is not null, then add it to where clause else do not bother . something like this.

CREATE OR REPLACE procedure context_vs_regular_variable(p_empno in integer,p_opt in integer default 1)
as
l_query varchar2(1000):='Select * from emp ';
p_data sys_refcursor;
l_rec emp%rowtype;
Begin
if p_empno is not null then
if p_opt=1
then
l_query:=l_query||' Where empno=:vempno ';
open p_data for l_query using p_empno;
else
dbms_session.set_context('my_context','empno',p_empno);
l_query:=l_query||' where empno = sys_context(''my_context'',''empno'') ';
open p_data for l_query;
end if;
end if;
fetch p_data into l_rec;
dbms_output.put_line(l_rec.empno||' '||l_rec.ename||' '||l_rec.salary||' '||l_rec.deptno);
end;
/

I am just pasing a value 1 or 2 to run it in a different way (if 1 is passed it will use regular approach, otherwise it will use "Sys_context" approach)

Can you tell me what's the difference between two approaches? there is same amount of coding and both use bind variables.
I have used contexts in some of my procedures and I am having hard time explaining it to my team.

Thanks,

Tom Kyte
July 21, 2005 - 6:09 pm UTC

the context is good when you don't know HOW MANY BINDS YOU HAVE during the open.

see the original example above, it is an example of when binding would be hard but sys_context'ing is not. You might have 0, 1, 2 or 3 binds.

Query

Tony, July 22, 2005 - 3:34 am UTC

Hi tom,

Can you please guide me how to impliment N+(N+1) logic in sql query

and looping in SQL.

Cheers
Tony

Tom Kyte
July 22, 2005 - 8:53 am UTC

what is n+(n+1) logic?

Query

Tony, July 25, 2005 - 8:45 am UTC

Tom,

The n (n+1) is nothing but in case if i have a table with 300 columns like
l_no_1
l_no_2
l_no_3
l_no_4
...
...
etc, when i say select from first column to 290 columns i have to write all the 290 columns...
so in case if we can incriment the value in the select statment then it will be easy.

Tony


Tom Kyte
July 25, 2005 - 9:08 am UTC

then I would say you built the table wrong, it should go down the page, not across the page.



Better Practice

A Reader, July 26, 2005 - 6:39 am UTC

Hi Tom,
There are a set of procedures used in the ETL process. The insert statements in these procedures insert millions of rows. All insert statements are written in procedures. My questions are:
1. If the inserts are stright forward ( direct ), is it OK to use them in procedures?
2. When using insert statements within a procedure, is it advisable to use cursors to insert them row wise?
3. In few procedures, cursors are used for direct inserts because, it has been assumed that in future there may be some processing required for each row before insert. Is this right to include it at this point (from performance point of view) when there is no processing required?
4. It is a common belief that it is not advisable to use direct inserts in DWH (unlike in OLTP systems) because millions of rows have to be inserted. Is this right?

Please clarify.
Thanks in advance.

Tom Kyte
July 26, 2005 - 8:16 am UTC

1) yes, IF and ONLY IF you cannot do it in a single bulk SQL statement in the first place

2) does not make sense to me. do not understand that comment

3) if you are saying "should I write code and do things slow by slow or use bulk SQL statements to do lots of stuff in a single sql statement", the answer is "do lots of stuff in a single sql statement"

4) You will have to define "direct" I think first, that has a specific connotation in Oracle (direct path inserts -- insert /*+ append */ into t select ......)

slow by slow processing (row by row processing) is not as good as

BIG BULKY SQL statement to do lots of stuff.




A reader, July 26, 2005 - 9:46 am UTC

Tom, I have to read data from a DW and send to a third party app - one time shot. The app that reads the data is a Java app but the result set of the query is nearly a billion rows.

If this was PL/SQL, I could use a cursor with bulk collect but I'm not sure the best way to handle such a large result set from Java / JDBC perspective. What is the best way to handle this large amount of data?

Tom Kyte
July 26, 2005 - 10:00 am UTC

I've got a pro*c app you can use if you want (see </code> http://asktom.oracle.com/~tkyte/flat/index.html <code>

java won't be "fast", but if you are going to do it that way, set your prefetch (connect/statement method) to say 500.

Query

Tony, July 26, 2005 - 12:24 pm UTC

Tom,

I thing u r not getting the question...

I have a table with around 200+ columns... and all it contains the values for specific account ...

the table looks like this

acct_cd tran_date l_acct_amt_1 l_acct_amt_2 l_acct_amt_3 .......... so on up to l_acct_amt_200

And each has some values for the each account with specific date..

and query will be like

select acct_no,tran_date case when l_acct_amt_1>100 then l_acct_amt_1+0.15 end 'Bonus, case when l_acct_amt_2>100 then l_acct_amt_2+0.15 end 'Bonus,
case when l_acct_amt_3>100 then l_acct_amt_3+0.15 end 'Bonus
....
...
from table name

now plz guide me to minimize the code ...

Thx
Tony

Tom Kyte
July 26, 2005 - 12:35 pm UTC

"u r" hmmmmmm, funny -- I'm not on a phone nor instant messaging with you. Oh well.


Anyway, I understood completely and totally. You have 200 columns when you should have 200 rows.

That is, you have data in record that should be cross record.


You have only one option right now -- list the columns you want. There are no "shortcuts" in SQL for that (thankfully, more people would put cross record dimensions in record perhaps if there were)



A reader, July 26, 2005 - 1:07 pm UTC

Tom, back to the DW unloading challenge... Thanks for the Pro*C reference. Even with the Pro*C, I'm concerned what the result set of a billion rows will do to the server side. I can process it in batches on the client but is there anything I can do to minimize the server impact of a result set that large?

Tom Kyte
July 26, 2005 - 1:10 pm UTC

fetching a billion rows via a full scan will be childs play for the database - it'll be gated by the client application (it'll only scan as fast as the client fetches).

Other than processing a full scan (no avoiding that), what are you worried about?

Context Names Weird behaviour

Maverick, August 01, 2005 - 5:38 pm UTC

Tom,

I am facing a weird problem from Application Contexts. I have created contexts for two packages. All the permissions were given.
Context1: ABC_STATUSTOEXPEND_SEARCH_CTX
Context2: ABC_EXPENDITURECODE_SEARCH_CTX

Package with context2 is working fine and could able to execute with different values. But context1 was giving "invalid sys.dbms_session privileges.." error.
I had this problem before and changed the name to
ABC_STATTOEXP_SEARCH_CTX (shortened it), and it's working without any errors(??)
I thought there was a problem with length of the context name i was using. But look at Context2 , it has one more character than context1 and still did not give any problems.

Any ideas on why it did not like first name for Context1?

I thought of giving you more information like my code and tables etc..but i do not think that's any relevant here because, by just changing name everything is working fine.

Thanks for any help you can provide me.


Tom Kyte
August 01, 2005 - 8:45 pm UTC

test case is where?

Ref cursor

A reader, August 03, 2005 - 11:47 am UTC

Tom,
I am trying to use one cursor to do multiple tasks
e.g If I have one cursor, I need to use the same cursor and pass it to multiple functions

create table test(id number);
insert into id values (1)
insert into id values (2)
insert into id values (3)

CREATE OR REPLACE PROCEDURE proc1 (p_cursor SYS_REFCURSOR) IS
TYPE array_t IS TABLE OF VARCHAR2(4000) iNDEX BY BINARY_INTEGER;
rec_array array_t;

BEGIN
FETCH p_cursor BULK COLLECT INTO rec_array;

FOR i IN rec_array.FIRST .. rec_array.LAST
LOOP
dbms_output.put_line('From proc1:'||rec_array(i));
END LOOP;
END proc1;

CREATE OR REPLACE PROCEDURE proc2 (p_cursor SYS_REFCURSOR) IS
TYPE array_t IS TABLE OF VARCHAR2(4000) iNDEX BY BINARY_INTEGER;
rec_array array_t;

BEGIN
FETCH p_cursor BULK COLLECT INTO rec_array;

FOR i IN rec_array.FIRST .. rec_array.LAST
LOOP
dbms_output.put_line('From proc2:'||rec_array(i));
END LOOP;
END proc2;


DECLARE
rec_array SYS_REFCURSOR;
BEGIN
OPEN rec_array FOR
'SELECT id FROM test';

proc1(rec_array);
proc2(rec_array);
close rec_array;

END;



Tom Kyte
August 03, 2005 - 12:10 pm UTC

you cannot, they would each have to get their "own" cursor. You fetch a row once.

Randy

Randy, August 19, 2005 - 7:12 pm UTC

I am a newbe, apart from the basic things from books, all the good things I learnt is from you TOM, I dont have previleges to creat CONTEXT so I tried out with "USING" I get this error, I dont see any mistake in my code, can you please help me resolve this problem thanks in advance.

SQL>   CREATE OR REPLACE TYPE emp_rec
  2     AS OBJECT
  3     ( empno number,
  4     sal number
  5    )
  6  /

Type created.

SQL>  CREATE OR REPLACE TYPE emp_table
  2  AS TABLE OF emp_rec
  3  /

Type created.

SQL> CREATE OR REPLACE FUNCTION emp_sal
  2  (p_deptno number,
  3  p_sal number
  4  )
  5  RETURN emp_table PIPELINED
  6  IS
  7   TYPE rc IS REF CURSOR;
  8    l_cursor rc;
  9    l_query  VARCHAR2(512)
 10                  DEFAULT ' SELECT
 11   empno,
 12   sal
 13  FROM
 14   emp
 15  WHERE
 16  1 = 1 ';
 17   cursor l_template IS SELECT empno,sal
 18   FROM emp;
 19   l_rec  l_template%rowtype;
 20  BEGIN
 21       IF  ( p_deptno IS NOT NULL ) THEN
 22            l_query := l_query ||
 23            ' AND deptno = : p_deptno ;' ;
 24     ELSE
 25            l_query := l_query ||
 26            ' AND sal > : p_sal ;' ;
 27     END IF;
 28  OPEN l_cursor FOR  l_query USING p_deptno, p_sal;
 29         LOOP
 30            FETCH l_cursor INTO l_rec;
 31            EXIT WHEN l_cursor%notfound;
 32       PIPE ROW(emp_rec(l_rec.empno, l_rec.sal));
 33         END LOOP;
 34        CLOSE l_cursor;
 35    RETURN;
 36    END;
 37  /

Function created.

SQL> select * from TABLE(seq_hours(20,1000));
select * from TABLE(seq_hours(20,1000))
                    *
ERROR at line 1:
ORA-00911: invalid character
ORA-06512: at "SCOTT.SEQ_HOURS", line 28
 

Tom Kyte
August 20, 2005 - 4:58 pm UTC

ctl-f for

Darko Egersdorfer

on this page to see how to do this without sys_context.

RANDY

RANDY, August 22, 2005 - 10:49 am UTC

Thank you for the response, I got this thing working, I got other problem, but I am unsure whether this fits in this section or not, I am very sorry if I have put it in a wrong place. I declared a cursor on the pipelined table and the parameters to the function, are passed from some other cursor I am not returned with any results, I tested the pipelined table by giving literals manually its working fine. Thank you for the help TOM

Tom Kyte
August 23, 2005 - 4:03 am UTC

need example.

how much memory

reader, August 22, 2005 - 3:35 pm UTC

Do you have a query to find out how much memory all of the open cursors use for a session? Also, how much memory each cursor uses? Thanks.

Nested cursors using JOIN

Mirela, August 31, 2005 - 11:30 am UTC

Hello Tom,

I also have a question regarding the cursors - is there a restriction saying that we can not use such a construct:

SELECT table1.A,
cursor (select table2.B, table3.C
from table2
inner join table3 on table2.D = table3.D
where table2.E = table1.E
)
FROM table1;

I get an internal error (ORA-00600) when trying to run such an sql.

Thank you!


Tom Kyte
August 31, 2005 - 1:59 pm UTC

ora-600 = contact support

Help with package design

TH, September 13, 2005 - 8:51 pm UTC

Tom,
Currently we have some packages written and all of them have dbms_session.set_context() calls in them. We are going to hire bunch of junior level developers to help us write many such packages. We decided to wrap set_context and sys_context calls in another package so that these new developers would just make a call to these functions in that package[ reason: since they are jr. level developers and would take considerable amount of time learning about application contexts,we do not want them worry about how to call context specific functions].

But i have a problem generalizing set_context and sys_context [as they are specific to a package].
Do you happen to have any ideas on how to implement Context calls ?

Any thoughts about this approach is greatly appreciated.

our code typically looks like this

package [package name]
..
procedure mysearch [parameter 1 in integer..parameter in integer]
is..

Begin
[for each parameter in the procedure ]
if (parameter1 is not null)
then
DBMS_SESSION.set_context ('Context_name1', 'p1_name', parameter1);

l_qry := l_qry || ' and [column_name] = sys_context( ''Context_name1'', ''p1_name'' ) ';
end if;

END;

Thanks,


Tom Kyte
September 13, 2005 - 9:01 pm UTC

I'm not sure what the question is?

A reader, September 13, 2005 - 10:48 pm UTC

Ok, Question is, is it possible to make that piece of code into generic function so that any developer using it will just call like this
if parameter1 is not null
then
set_and_call_context(parameter1,column1,data_type);
end if;

and that is all they have to do.
my set_and_call_context function will accept those 3 parameters and build code as i mentioned before.

Can I do something like that? i am having a hard time creating a generic function like that.

Thanks

Tom Kyte
September 14, 2005 - 8:05 am UTC

the context is bound to a particular procedure or package, your generic package would have to be named on every context you have.

Frankly, I fail to see how this is "easier" or "less scary" then dbms_session.set_context() would be.

Little bit complex for novice developers

A reader, September 14, 2005 - 10:45 am UTC

Thanks for your response. I think it's difficult for their novice minds because, while constructing string they have to worry about double quotes and concatenation etc..and make sure they use different context names. they should know what's a context name and why we use it etc..

Not all ofthem are from Oracle background. they have different backgrounds and have different syntaxes in mind.

To avoid all these questions if there is a way to built a generic one, all they do is call that function.

Thought that would make their life easy.

Tom Kyte
September 14, 2005 - 11:46 am UTC

ahh, I'm sort of getting it now....

How about this:

ops$tkyte@ORA9IR2> create or replace package ctx_set
  2  as
  3          function value( p_cname    in varchar2,
  4                      p_operator in varchar2,
  5                      p_val      in varchar2 ) return varchar2;
  6
  7          function value( p_cname    in varchar2,
  8                      p_operator in varchar2,
  9                      p_val      in number ) return varchar2;
 10
 11          function value( p_cname    in varchar2,
 12                      p_operator in varchar2,
 13                      p_val      in date ) return varchar2;
 14
 15  end;
 16  /
 
Package created.
 
ops$tkyte@ORA9IR2> create or replace context my_ctx using ctx_set;
 
Context created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> create or replace package body ctx_set
  2  as
  3          function value( p_cname    in varchar2,
  4                      p_operator in varchar2,
  5                      p_val      in varchar2 ) return varchar2
  6          is
  7          begin
  8                  if ( p_val is null )
  9                  then
 10                          return null;
 11                  end if;
 12                  dbms_session.set_context( 'my_ctx', p_cname, p_val );
 13                  return ' and ' || p_cname || ' ' || p_operator || ' '  || 'sys_context( ''my_ctx'', '''|| p_cname || ''')';
 14          end;
 15
 16          function value( p_cname    in varchar2,
 17                      p_operator in varchar2,
 18                      p_val      in number ) return varchar2
 19          is
 20          begin
 21                  if ( p_val is null )
 22                  then
 23                          return null;
 24                  end if;
 25                  dbms_session.set_context( 'my_ctx', p_cname, p_val );
 26                  return ' and ' || p_cname || ' ' || p_operator || ' '  || 'to_number(sys_context( ''my_ctx'', '''|| p_cname || '''))';
 27          end;
 28
 29          function value( p_cname    in varchar2,
 30                      p_operator in varchar2,
 31                      p_val      in date ) return varchar2
 32          is
 33          begin
 34                  if ( p_val is null )
 35                  then
 36                          return null;
 37                  end if;
 38                  dbms_session.set_context( 'my_ctx', p_cname, to_char(p_val,'yyyymmddhh24miss' ) );
 39                  return ' and ' || p_cname || ' ' || p_operator || ' '  || 'to_date(sys_context( ''my_ctx'', '''|| p_cname || '''),''yyyymmddhh24miss'')';
 40          end;
 41
 42  end;
 43  /
 
Package body created.
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> pause
 
ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> create or replace
  2  procedure my_procedure( p_ename   in varchar2 default NULL,
  3                          p_hiredate  in date default NULL,
  4                          p_sal       in number default NULL)
  5  as
  6      type rc is REF CURSOR;
  7
  8      l_cursor rc;
  9      l_query  varchar2(512)
 10               default 'select * from emp where 1 = 1 ';
 11
 12      cursor l_template is select * from emp;
 13      l_rec  l_template%rowtype;
 14
 15  begin
 16          l_query := l_query || ctx_set.value( 'ename', 'like', '%'||upper(p_ename)||'%' );
 17          l_query := l_query || ctx_set.value( 'hiredate', '>', p_hiredate );
 18          l_query := l_query || ctx_set.value( 'sal', '>', p_sal );
 19      p( l_query );
 20      open l_cursor for l_query;
 21      loop
 22          fetch l_cursor into l_rec;
 23          exit when l_cursor%notfound;
 24
 25          dbms_output.put_line( l_rec.ename || ',' ||
 26                                l_rec.hiredate || ',' ||
 27                                l_rec.sal );
 28      end loop;
 29
 30      close l_cursor;
 31  end;
 32  /
 
Procedure created.


it behaves a tad different with respect to the LIKE i had on ename (since we add '%', it is never "null") -- something to be aware of.
 

Thanks Tom.. But..

A reader, September 14, 2005 - 12:47 pm UTC

I can use this code with some minor changes as per my requirement. Thanks for this one.
But i still have one question .

You have created context for ctx_set package. But the query we are executing [actually opening refcursor] is from called procedure. Won't this give error since Context is being used in this procedure,but actually created for another?


Thanks for all your help [again]


Tom Kyte
September 14, 2005 - 1:34 pm UTC

dbms_session is what checks that it is being called from the right place.

The calls to sys_context are available anywhere

That is, you can READ a context value from anything
You can only SET a context value from the single package

A reader, October 07, 2005 - 8:14 am UTC

Tom,
May i know the difference between using "SYS_CONTEXT" and :USING clause to
bind variables in dynamic Ref Cursor?
Thanks..



Tom Kyte
October 07, 2005 - 9:16 am UTC

the difference is minimal, they achieve the same effect.

if you know the number of binds at compile time, by all means using "using"

if you do not, the use of sys_context will allow you to dynamically construct the query, referencing just the sys_context values you need - be it 1, 2, or 300 of them.

Cursor

Anne, October 18, 2005 - 4:16 pm UTC

Hi Tom,

I hope my problem is relevant to the existing thread. If not please let me know. I will try describe my problem as best as I can. I have the following requirement :
hrs_cur : cursor for project-emp-hours in the current period.
distinct project_array : for distinct project_id in hrs_cur
distinct emp_array : for distinct emp_id in hrs_cur
distinct proj_emp_array : for distinct project_id, emp_id in hrs_cur.
FOr every row in the hrs_cur do processing and update the proj_array, emp_array.....

My question is : Is there a better way for building the emp, proj, and emp_proj arrays so that I do not have to duplicate the query for hrs_cur ? I want to avoid creating a view for hrs_cur. Thanks so much!

My code is as follows :
declare
cursor hrs_cur is
SELECT agency_nr, customer_id,
project_id .......
from ....;

TYPE proj_rec_type IS RECORD (
project_id bps_project.project_id%TYPE
, proj_max bps_project.max_bill_amt%TYPE
, proj_bal bps_project.max_bill_amt%TYPE
);

TYPE proj_type IS TABLE OF .....;
TYPE emp_type IS TABLE OF .....;
TYPE proj_emp_type is TABLE OF .... ;

proj_array proj_type;
emp_array emp_type;
proj_emp_array proj_emp_type;
begin

---Build proj_array
for x in
(SELECT project_id, proj_bal
from proj_table
where project_id in
( select distinct project_id
<from the query for hrs_cur>
)
loop
proj_array(x.project_id) := x.proj_bal;
end loop;

---Build emp_qrray
for x in
(SELECT emp_id, cost_to_date
from emp_table
where emp_id in
( select distinct emp_id
<from the query for hrs_cur>
)
loop
emp_array(x.emp_id) := x.cost_to_date;
end loop;


--- Build proj_emp_array
for x in
(SELECT project_id, emp_id, proj_emp_id
from proj_emp table
where (project_id, emp_id) in
(select distinct project_id, emp_id
<from the query for hrs_cur>
)
loop
proj_emp_array(x.project_id) := x.proj_emp_id;
end loop;

Open hrs_cur;
fetch hrs_cur bulk collect into hrs_tab;
Close hrs_cur;

for i in 1 .. hrs_tab.count
loop
<do some processing and set the 'balances' in the emp_array, proj_array
and emp_proj_array.....>
end loop;

exception
when OTHERS then
dbms_output.put_line (DBMS_UTILITY.FORMAT_ERROR_STACK);
end;




Tom Kyte
October 18, 2005 - 5:30 pm UTC

UGH -- get rid of the when others without a raise right after it - just delete it, it is useless, actually less than useless! the only thing it would/could do is HIDE the fact that an error occurred!!! get rid of it.


since you never need distinct on a subquery like that......


but why not join emp -> proj_emp <- project

and where (project_id, emp_id) in (.....)


one query - three way join, one subquery...



cursor within cursor

A reader, October 25, 2005 - 1:10 pm UTC

Hi Tom,

I have 2 tables psum and atr

create table psum
(
action varchar2(4),
actiondate date,
count number
);

create table atr
(
timestamp date,
action varchar2(4),
description varchar2(2000)
);

Assuming the 2 tables are populated as follows:

insert into psum values('A301', '10-20-2005', 6000);
insert into psum values('A302', '10-20-2005', 400);
insert into psum values('A301', '10-21-2005', 2021);
insert into psum values('A302', '10-21-2005', 300);
insert into psum values('A301', '10-22-2005', 5664);
insert into psum values('A302', '10-22-2005', 100);
insert into psum values('A301', '10-23-2005', 7776);
insert into psum values('A302', '10-23-2005', 342);

insert into atr values ('10-20-2005', 'CC01', 'Action Dec 1');
insert into atr values ('10-20-2005', 'CC02', 'Action Dec 2');
insert into atr values ('10-20-2005', 'CC03', 'Action Dec 3');
insert into atr values ('10-21-2005', 'CC01', 'Action Dec 1');
insert into atr values ('10-21-2005', 'CC02', 'Action Dec 2');
insert into atr values ('10-22-2005', 'CC01', 'Action Dec 1');
insert into atr values ('10-22-2005', 'CC02', 'Action Dec 2');
insert into atr values ('10-23-2005', 'CC01', 'Action Dec 1');
insert into atr values ('10-23-2005', 'CC02', 'Action Dec 2');
insert into atr values ('10-23-2005', 'CC03', 'Action Dec 3');
insert into atr values ('10-23-2005', 'CC04', 'Action Dec 4');


Now I have a request for a report where the inputs will be a from-date and a to-date and the data should be returned from these 2 tables. But both these tables are like auditing tables and they dont have any column which is in common between these 2 tables.

For eg., if the input from date is 10-20-2005 and input to date is 10-22-2005 then I need a report like

Date Count from psum Count from atr
10-20-2005 6400 3
10-21-2005 2321 2
10-22-2005 5764 2

What is the easiest way to achieve this. Please help.

Thanks.


Tom Kyte
October 26, 2005 - 8:53 am UTC

ops$tkyte@ORA10GR2> select dt, sum(cntp), sum(cnta)
  2    from ( select actiondate dt, sum(count) cntp, to_number(null) cnta
  3             from psum
  4                    where actiondate between to_date('01-20-2005') and to_date('10-22-2005')
  5                    group by actiondate
  6                    union all
  7                   select timestamp dt, null, count(*)
  8                     from atr
  9                    where timestamp between to_date('01-20-2005') and to_date('10-22-2005')
 10                    group by timestamp
 11             )
 12   group by dt;

DT          SUM(CNTP)  SUM(CNTA)
---------- ---------- ----------
10-20-2005       6400          3
10-21-2005       2321          2
10-22-2005       5764          2

 

Using "COMMIT" or "ROLLBACK" inside PLSQL

Rahul Dutta, October 28, 2005 - 4:14 pm UTC

Hi Tom,

From my point of view, we should not use "COMMIT" or "ROLLBACK" inside the PLSQL code, it should be passed from the application or from the interface from where we are executing it.
I'm falling short of Datapoints to clarify my point except one that is we can reduce the level of damage from erroneous calling of such Procedures.
Please let me know, if my point is correct and provide me some more Datapoints.

I also strongly feel that Issuing Commit is the responsibility of the Interface/application which calls that particular PLSQL code.

Thanks

Rahul

P.S: I've also checked in Metalink that there is BUG # 3768052 for versions >= 9.0 but < 10.2

Tom Kyte
October 29, 2005 - 10:53 am UTC

I agree with you 100% and have written as much in my books over and over.


The client is the only thing that knows WHAT the transaction is. Perhaps the client thinks that updating the address and updating the phone number is the transaction - if you have a procedure to do each - and they each commit, well, the client cannot use them!


commits belong in the control of the client - the "master" of the session.

no better

James, November 10, 2005 - 12:16 am UTC

Well I've moved to using set_context and execute immediate with bulk collect and performance is worse.

Previously, to solve the problem of an unknown number of binds, I had a small procedure which returned an open cursor, which looked something like that:

procedure open_bound_cursor(
sql_statement in varchar2,
bind_array in owa.vc_arr,
bound_cur in out CurType)
is

bind_count number := bind_array.count;

begin

if bind_count = 0 then
open bound_cur for sql_statement;
elsif bind_count = 1 then
open bound_cur for sql_statement
using bind_array(1);
elsif bind_count = 2 then
open bound_cur for sql_statement
using bind_array(1),bind_array(2);

etc etc etc ...

So I would parse my parameters, call this procedure and loop through the cursor. I even had a subquery in the loop! I also in my new code moved the subquery into the bulk collected collection! Still no quicker!

Here are the original stats (1,000 searches)

OVERALL TOTALS FOR ALL RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 6058 2.40 2.71 1 31 0 0
Execute 7071 9.18 9.95 0 9306 0 0
Fetch 53346 149.06 184.82 1148 4353386 0 3631670
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 66475 160.64 197.49 1149 4362723 0 3631670

Misses in library cache during parse: 216

Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
db file sequential read 964 1.89 20.20
db file scattered read 67 0.00 0.02
latch free 174 0.05 0.94
buffer busy waits 4 0.13 0.13



Here is the "new and immproved" bulk collected, sql typed subquery, context set for the same 1,000 searches:

OVERALL TOTALS FOR ALL RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 5149 3.95 4.56 10 5052 0 0
Execute 7186 7.83 8.75 0 6855 0 0
Fetch 41553 172.91 192.33 2588 4490619 0 3623877
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 53888 184.69 205.66 2598 4502526 0 3623877

Misses in library cache during parse: 259
Misses in library cache during execute: 1

Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
db file sequential read 2070 1.16 2.31
latch free 297 0.08 0.88
db file scattered read 205 0.01 0.03


More CPU, greater elapsed time, *very* dissapointed.

Regards,
James






Tom Kyte
November 11, 2005 - 11:34 am UTC

you need to give "a concrete example"

in the grand scheme of things - this does not look significantly different - and in fact since they did obviously different things - hard to compare.

re:no better (new tkprofs)

James, November 10, 2005 - 12:46 am UTC

There might have been a few too many other things running when I posted the first 2 trace files so here they are again (with a sql statement removed)

OLD WAY

OVERALL TOTALS FOR ALL RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 4067 1.60 2.15 0 18 0 0
Execute 5065 5.70 6.58 0 3901 0 0
Fetch 48617 116.50 132.53 1019 3145537 0 3335117
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 57749 123.80 141.27 1019 3149456 0 3335117

Misses in library cache during parse: 112

Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
latch free 256 0.13 1.01
db file sequential read 683 0.28 0.63
db file scattered read 142 0.00 0.01
buffer busy waits 2 0.00 0.00




NEW WAY
OVERALL TOTALS FOR ALL RECURSIVE STATEMENTS

call count cpu elapsed disk query current rows
------- ------ -------- ---------- ---------- ---------- ---------- ----------
Parse 3261 1.75 2.11 1 27 0 0
Execute 5260 6.39 7.49 0 6276 0 0
Fetch 36897 141.81 171.66 1131 3186321 0 3333796
------- ------ -------- ---------- ---------- ---------- ---------- ----------
total 45418 149.95 181.27 1132 3192624 0 3333796

Misses in library cache during parse: 135

Elapsed times include waiting on following events:
Event waited on Times Max. Wait Total Waited
---------------------------------------- Waited ---------- ------------
db file sequential read 754 0.25 0.41
latch free 203 0.22 1.92
db file scattered read 157 0.11 0.12
buffer busy waits 1 0.03 0.03



Tom Kyte
November 11, 2005 - 11:35 am UTC

so, did you stop to compare the plans and see if one of them changed or not.

columns in refcursor

Oleg Oleander, November 10, 2005 - 8:33 am UTC

Dear Tom,

Until now, I was sure that the client has no way to "look into" the column count, column type, column name of the refcursor returned by the server. So the clinet must know the structure of the returned data in advance. But I saw a feature in TOAD that I cannot imagine how that works:

select Function(a,b,c) from dual;

returns a refcursor, than I right-click the returned one column row and I am able to view the data in the refursor.

How can that be?

Also, is there a way to convert a refcursor to the simple SQL if I know the columns that are in the refcursor? (I'd need it for a workaround)
like:
select col1, col2 from (Cursor)

Thank you very much for your time.

Oleg.

Tom Kyte
November 11, 2005 - 11:49 am UTC

if you return a strongly typed cursor, you can describe it before hand.


ops$tkyte@ORA10GR2> create or replace package my_pkg
  2  as
  3          type rc is ref cursor return emp%rowtype;
  4  end;
  5  /

Package created.

ops$tkyte@ORA10GR2>
ops$tkyte@ORA10GR2> create or replace function foo return my_pkg.rc
  2  as
  3  begin
  4          null;
  5  end;
  6  /

Function created.

ops$tkyte@ORA10GR2>
ops$tkyte@ORA10GR2> desc foo
FUNCTION foo RETURNS REF CURSOR
                                RECORD                  OUT
     EMPNO                      NUMBER(4)               OUT
     ENAME                      VARCHAR2(10)            OUT
     JOB                        VARCHAR2(9)             OUT
     MGR                        NUMBER(4)               OUT
     HIREDATE                   DATE                    OUT
     SAL                        NUMBER(7,2)             OUT
     COMM                       NUMBER(7,2)             OUT
     DEPTNO                     NUMBER(2)               OUT

ops$tkyte@ORA10GR2>



I don't know what you mean by the last part - to convert a ref cursor to sql??? doesn't make sense to me. 

REOPEN/REUSE REF CURSOR

Laxman Kondal, November 10, 2005 - 12:55 pm UTC

Hi Tom

I want to reopen/reuse ref_cursor which comes in as parameter and I did this test to reopen but didn't work.

scott@ORCL10G> CREATE OR REPLACE PROCEDURE P
2 AS
3 TYPE ref_cur IS REF CURSOR;
4 v_ref ref_cur;
5 c_ref ref_cur;
6 --
7 rec_emp Emp%ROWTYPE;
8 --
9 BEGIN
10 OPEN v_ref FOR SELECT * FROM Emp WHERE ROWNUM <5;
11 --
12 c_ref := v_ref; -- i am not sure why this didn't work
13 --
14 LOOP
15 FETCH v_ref INTO rec_emp;
16 EXIT WHEN v_ref%NOTFOUND;
17 DBMS_OUTPUT.PUT_LINE(rec_emp.ename);
18 END LOOP;
19 --
20 CLOSE v_ref;
21 --
22 LOOP
23 FETCH c_ref INTO rec_emp;
24 EXIT WHEN c_ref%NOTFOUND;
25 DBMS_OUTPUT.PUT_LINE(rec_emp.ename);
26 END LOOP;
27 --
28 CLOSE c_ref;
29 --
30 END;
31 /

Procedure created.

scott@ORCL10G> exec p
SMITH
ALLEN
WARD
JONES
BEGIN p; END;

*
ERROR at line 1:
ORA-01001: invalid cursor
ORA-06512: at "SCOTT.P", line 23
ORA-06512: at line 1


scott@ORCL10G>

Is there any way or work around to reuse this ref cursor.

Thanks and regards.


Tom Kyte
November 11, 2005 - 11:56 am UTC

you cannot, you would need two result sets, ref cursors are "pointers", they both pointed to the same result set (that is the "ref" in "ref cursor")

REOPEN/REUSE REF_CURSOR

Laxman Kondal, November 11, 2005 - 10:23 am UTC

Hi Tom

I could do this as work around:

scott@ORCL10G> CREATE OR REPLACE PROCEDURE P
2 AS
3 --
4 TYPE ref_cur IS REF CURSOR;
5 v_result ref_cur;
6 --
7 rec1 Emp%ROWTYPE;
8 --
9 TYPE emp_array IS TABLE OF Emp%ROWTYPE INDEX BY BINARY_INTEGER;
10 --
11 emp_data emp_array;
12 --
13 BEGIN
14 --
15 OPEN v_result FOR SELECT * FROM Emp WHERE ROWNUM < 5;
16 --
17 FETCH v_result BULK COLLECT INTO emp_data;
18 CLOSE v_result;
19 --
20 FOR i IN 1..emp_data.COUNT LOOP
21 rec1 := emp_data(i);
22 DBMS_OUTPUT.PUT_LINE('FirstTime '||
23 rec1.empno||'-'||
24 rec1.ename);
25 END LOOP;
26 --
27 FOR i IN 1..emp_data.COUNT LOOP
28 rec1 := emp_data(i);
29 DBMS_OUTPUT.PUT_LINE('SecondTime '||
30 rec1.empno||'-'||
31 rec1.ename||'-'||
32 rec1.mgr);
33 END LOOP;
34 --
35 --
36 DBMS_OUTPUT.PUT_LINE('Since you fetched ref cursor once its invalid as empty to fetch any thing');
37 --
38 LOOP
39 FETCH v_result INTO rec1;
40 EXIT WHEN v_result%NOTFOUND;
41 DBMS_OUTPUT.PUT_LINE(rec1.empno);
42 END LOOP;
43 --
44
45 END;
46 /

Procedure created.

scott@ORCL10G> exec p
FirstTime 7369-SMITH
FirstTime 7499-ALLEN
FirstTime 7521-WARD
FirstTime 7566-JONES
SecondTime 7369-SMITH-7902
SecondTime 7499-ALLEN-7698
SecondTime 7521-WARD-7698
SecondTime 7566-JONES-7839
Since you fetched ref cursor once its invalid as empty to fetch any thing
BEGIN p; END;

*
ERROR at line 1:
ORA-01001: invalid cursor
ORA-06512: at "SCOTT.P", line 39
ORA-06512: at line 1


scott@ORCL10G>


Is this the right way to work around reuse of ref cursor?

Thanks and regards

Tom Kyte
November 12, 2005 - 8:38 am UTC

no - not in general, because in general result sets are not of trival size. I don't want thousands of records in an index by table.

The "work around" to me is not to process the same data twice, that is somewhat inefficient.

columns in sys_refcursor (9.2.0.3)

Oleg Oleander, November 12, 2005 - 3:46 am UTC

Dear Tom,

Thank you for the your answer. 

I use sys_refcursor as below:

SQL> create or replace function foo return sys_refcursor
  2   as
  3   begin
  4           null;
  5   end;
  6  /

A függvény létrejött.

SQL> desc foo
FUNCTION foo RETURNS REF CURSOR

What sql sqlplus is submitting for a desc commnad?

As for the second part:

Is there a way to use a cursor like a view in an sql statement. Like I could join it for exapmle. Like:

select t.col1, t.col2, c.col1 from sometable t, foo c;

I know that it is a bit silly, since one could make all necessary joins and selects in the refcursor's sql itself,
or one could return a table type instead of a refcursor, but i am just interested.  

Thank you for your help again.

Best regards,

Oleg 

Tom Kyte
November 12, 2005 - 10:56 am UTC

then no one can tell you what that returns UNTIL RUNTIME, when they run it, they get a cursor back and they can describe that cursor.


sqlplus isn't using sql to describe, it is using an API to describe things, a function call.



You can use functions in SQL - but not functions that return ref cursors (result sets), you use pipelined functions - functions that return "piped data", much like a table - a row at a time.




how to describe the returned refcursor?

Oleg Oleander, November 12, 2005 - 1:20 pm UTC

Dear Tom,

1: Would you please tell me the package name with which I can - or sqlplus can - describe the returned refcursor?

2: I understand your explanation, but I was curios that I may miss something.

Thank you very much. Your site is great!

Oleg.

Tom Kyte
November 12, 2005 - 1:39 pm UTC

1) plsql cannot (not yet) - CLIENTS can (vb, java, C, whatever). SQLPlus does right before you PRINT the ref cursor - but there is no "desc ref_cursor" command or anything like that.



still, TOAD does it somehow

Oleg Oleander, November 13, 2005 - 7:07 pm UTC

I am still curious how TOAD can do this (describing the returned ref_cursor). Or is they using some undocumented api?

Thank you

Tom Kyte
November 14, 2005 - 7:49 am UTC

toad is a C program (or some client language)

Toad is using the same API (oci ultimately) that SQLPlus is using.

For the same reason that sqlplus can figure out what the column names are, their types, their lengths (it described the cursor), toad can.

Nothing special or magic, toad is a client program and as stated - client programs can procedurally process a ref cursor after describing it.



Interesting, but could I use as dynamic return-cursor from function ?

Stein Andersen, November 17, 2005 - 12:39 pm UTC

Is there possible to build a REFERENCE_CURSOR, such that not only the WHERE-Part, but also the SELECT-Part is dynamic.
And further is it possible to return such a CURSOR back from a function, currently the function is called from IIS trough ADO.

Have now created oracle functions for generating and sorting a "temp-table", used as cache for paging/sorting from application. The functions are generic so the SQL's (used as subqery) is currently received as a parameter, and executed using EXECUTE IMMEDIATE into the "temp-table". SQL will have different number of attributes in the select-part depending on use.

Currently the function(s) are only returning "number of rows", actual rows are fetched using seperat SQL. Wants them to return a cursor for the records on each page if possible.


Tom Kyte
November 18, 2005 - 9:44 am UTC

yes, because you can:


open ref_cursor for l_plsql_string_holding_any_query_you_want_to_construct;


but this is the way I paginate through result sets on the web (and it does not involve temporary tables...)

</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:127412348064 <code>

getting "invalid cursor" error

Dhamo, November 26, 2005 - 7:59 am UTC

Dear Tom,

I have the following function, that works fine
with 9i databases & fails with "invalid cursor" err in 10G.
#######
Create or Replace FUNCTION fun RETURN INTEGER IS

FLAG integer default 0;
CNT integer default 0;

CURSOR Test_C IS
         SELECT OWNER, TABLE_NAME
         FROM ALL_CONSTRAINTS
     where OWNER NOT IN ('SYS', 'SYSTEM');

BEGIN
     FOR KEY IN Test_C
     LOOP

    <<PROCESS_NEXT>>    
           CNT := CNT + 1;
       IF (FLAG = 1) THEN
         BEGIN
           FETCH Test_C into KEY;    --- This works fine in 9i, but fails in 10G with "invalid cursor" err
           FLAG := 0;
         END;
       END IF;
    
    IF ( CNT = 3 ) THEN   -- if this condition received
       BEGIN
        FLAG := 1;
        GOTO PROCESS_NEXT;  --- i wanted to go back and fetch for the next record in the cursor.
       END;
    END IF;
        --  additional code ....
      END LOOP;
      RETURN 0;
End;
/
########

I'm receiving "invalid cursor" error while running in 10G
eventhough funciton is created successfully.
######
SQL> select fun from dual;
select fun from dual
       *
ERROR at line 1:
ORA-01001: invalid cursor
ORA-06512: at "TEST.FUN", line 19
######

Could you pls help me what's Ora 10G is expecting here.

Thanks so much for your time.

-Dhamdaran 

Tom Kyte
November 26, 2005 - 12:38 pm UTC

it should never have worked - that is an amazing piece of code there.  

You have an IMPLICIT cursor that you are fetching from explicitly.  I'm sorry there was a bug in 9i that allowed this code to accidently appear to execute properly - but it really needs to be rewritten.

that code is somewhat scary - lots of things wrong with it - goto not withstanding, the fetch test_c into key is the scariest part of it all.


consider:

ops$tkyte@ORA9IR2> create table t ( a int );

Table created.

ops$tkyte@ORA9IR2> insert into t values ( 1 );

1 row created.

ops$tkyte@ORA9IR2> insert into t values ( 2 );

1 row created.

ops$tkyte@ORA9IR2> insert into t values ( 3 );

1 row created.

ops$tkyte@ORA9IR2>
ops$tkyte@ORA9IR2> declare
  2          cursor c is select * from t;
  3  begin
  4          for x in c
  5          loop
  6                  dbms_output.put_line( x.a );
  7                  fetch c into x;
  8                  dbms_output.put_line( x.a );
  9          end loop;
 10  end;
 11  /
1
2
3
3

PL/SQL procedure successfully completed.

ops$tkyte@ORA9IR2> insert into t values ( 4 );

1 row created.

ops$tkyte@ORA9IR2> declare
  2          cursor c is select * from t;
  3  begin
  4          for x in c
  5          loop
  6                  dbms_output.put_line( x.a );
  7                  fetch c into x;
  8                  dbms_output.put_line( x.a );
  9          end loop;
 10  end;
 11  /
1
2
3
4

PL/SQL procedure successfully completed.


1,2,3,3 <<<=====!!!!


fortunately for us, 10g has fixed this bad bug:

ops$tkyte@ORA10GR2> declare
  2          cursor c is select * from t;
  3  begin
  4          for x in c
  5          loop
  6                  dbms_output.put_line( x.a );
  7                  fetch c into x;
  8                  dbms_output.put_line( x.a );
  9          end loop;
 10  end;
 11  /
1
declare
*
ERROR at line 1:
ORA-01001: invalid cursor
ORA-06512: at line 7


You cannot explicitly process an implicit cursor. 

Thanks

Dhamo, November 28, 2005 - 12:08 am UTC

Dear Tom,

Thanks for explaining the bug with clear examples.
It's very much helpful to understand the differences
between 9i & 10g.

Many thanks,
Dhamodaran.

PLEASE HELP

A reader, January 04, 2006 - 5:52 pm UTC

please see and help me getting the output


begin
for a in (select dname || ' has '||count(*) ||' employees '
from emp e,dept d
where e.deptno=d.deptno
group by dname)
loop
dbms_output.put_line(a.dname || ' has '||a.count(*) ||' employees ');
end LOOP;
end;

thanks


Tom Kyte
January 05, 2006 - 9:24 am UTC

for a in ( select <expression> AS YOUR_NAME
from ... )
loop
dbms_output.put_line( a.YOUR_NAME );



you are selecting an expression - name it.

reader

A reader, January 05, 2006 - 12:19 pm UTC

Hi Tom

like we can measure the performance of a sql statement with the help of an explain plan ..how can we measure the performance of a procedure or function or a cursor.....

thanks..

Tom Kyte
January 05, 2006 - 1:18 pm UTC

you cannot measure the performance of a sql statement with an explain plan. You can only see what sort of execution will take place at run time.

A cursor is simply SQL - so you would use sql_trace to measure the performance of SQL (sql_trace it, tkprof the trace file, read the report)

you can use dbms_profiler (search this site for examples) in a similar manner for your plsql.

reader

A reader, January 06, 2006 - 7:45 pm UTC

Hi Tom ,

How are you..i recently got a test on cursor ..two of the questions i wanted to share with you are ....


question 1
-----------
which of the following statements correctly identify the differences between strong and weak ref cursors

1)
you can use weak ref cursor to declare a cursor vaiable THAT CAN FETCH ROWS FROM ANY SQL STATEMENT

2)
a strong ref cursor offers strong performance and should be used whenever possible to improve program efficiency

3)
using weak ref cursor means you have to deal more often with runtime errors as oppossed to compile time error for strongly typed ref cursors

4)
you must close a cursor variable based on strong ref cursor twice because it persists (strongly) past the first close

5)
a cursor variable based on strong ref cursor fetches data only into a record whose structure is compatible with return clause in the ref cursor

for this above question i gave the answers as 2,3,5(which i thought were correct)..but the answers were 1,2,5...could you please expalin why is that..like why 1 is correct and 3 is NOT CORRECT.


question 2
-----------

which of the following scenerios call for the use of ref cursor?

a)
various application components including an oracle form application and several stored procedures all need to work with the same resultset

b)
the colums to be queried and the tables from which to be queried are not known until run time

c)
you have six different queries,all exectly same exept for the different order by clause. you need to write a program to display the data from each query

d)
you need to reduce the networkj traffic between client and the server oracle programs

e)
you want to let the user supply the where clause to apply to otherwise standardized query

the answer is a,c,d but i gave as a d e may i know why e should not be there as answer





Tom Kyte
January 07, 2006 - 10:08 am UTC

the <b>correct</b> answer for question 1 is 1, 3, 5.

1 - a weakly typed cursor variable can fetch from arbitrary sql statements - the number and types of the selected columns may vary.  a strongly typed ref cursor can only fetch from queries that have the same number of columns and that are type compatible.


ops$tkyte@ORA10GR2> create or replace package types
  2  as
  3          type weak       is ref cursor;
  4          type strong is ref cursor return all_objects%rowtype;
  5  end;
  6  /

Package created.

ops$tkyte@ORA10GR2>
ops$tkyte@ORA10GR2> declare
  2          x       types.weak;
  3  begin
  4          open x for select cursor(select count(*) from dual), 1 from dual;
  5          close x;
  6          open x for select 1, sysdate, 'hello world' from dual;
  7          close x;
  8  end;
  9  /

PL/SQL procedure successfully completed.

ops$tkyte@ORA10GR2>
ops$tkyte@ORA10GR2> declare
  2          x       types.strong;
  3  begin
  4          open x for select cursor(select count(*) from dual), 1 from dual;
  5  end;
  6  /
        open x for select cursor(select count(*) from dual), 1 from dual;
                   *
ERROR at line 4:
ORA-06550: line 4, column 13:
PLS-00382: expression is of wrong type
ORA-06550: line 4, column 2:
PL/SQL: SQL Statement ignored


ops$tkyte@ORA10GR2>
ops$tkyte@ORA10GR2> declare
  2          x       types.strong;
  3  begin
  4          open x for select * from all_objects;
  5  end;
  6  /

PL/SQL procedure successfully completed.



2 - <b>does not apply</b>, it is not part of the answer.  Weak and Strong ref cursors perform identicially.  Strong ref cursors have some compile time advantages in the area of TYPE CHECKING, but at run time - - they are "the same"

ops$tkyte@ORA10GR2> create or replace package types
  2  as
  3          type weak       is ref cursor;
  4          type strong is ref cursor return all_objects%rowtype;
  5  end;
  6  /

Package created.

ops$tkyte@ORA10GR2>
ops$tkyte@ORA10GR2> create or replace procedure weak_cur
  2  as
  3          l_cur   types.weak;
  4          l_rec    all_objects%rowtype;
  5          type array is table of all_objects%rowtype index by binary_integer;
  6          l_array  array;
  7  begin
  8          open l_cur for select * from all_objects;
  9          loop
 10                  fetch l_cur into l_rec;
 11                  exit when l_cur%notfound;
 12          end loop;
 13          close l_cur;
 14          open l_cur for select * from all_objects;
 15          loop
 16                  fetch l_cur bulk collect into l_array limit 100;
 17                  exit when l_cur%notfound;
 18          end loop;
 19          close l_cur;
 20  end;
 21  /

Procedure created.

ops$tkyte@ORA10GR2> create or replace procedure strong_cur
  2  as
  3          l_cur   types.strong;
  4          l_rec    all_objects%rowtype;
  5          type array is table of all_objects%rowtype index by binary_integer;
  6          l_array  array;
  7  begin
  8          open l_cur for select * from all_objects;
  9          loop
 10                  fetch l_cur into l_rec;
 11                  exit when l_cur%notfound;
 12          end loop;
 13          close l_cur;
 14          open l_cur for select * from all_objects;
 15          loop
 16                  fetch l_cur bulk collect into l_array limit 100;
 17                  exit when l_cur%notfound;
 18          end loop;
 19          close l_cur;
 20  end;
 21  /

Procedure created.

ops$tkyte@ORA10GR2>
ops$tkyte@ORA10GR2> exec runStats_pkg.rs_start

PL/SQL procedure successfully completed.

ops$tkyte@ORA10GR2> exec weak_cur

PL/SQL procedure successfully completed.

ops$tkyte@ORA10GR2> exec runStats_pkg.rs_middle

PL/SQL procedure successfully completed.

ops$tkyte@ORA10GR2> exec strong_cur

PL/SQL procedure successfully completed.

ops$tkyte@ORA10GR2> exec runStats_pkg.rs_stop(100)
Run1 ran in 628 hsecs
Run2 ran in 628 hsecs
run 1 ran in 100% of the time

Name                                  Run1        Run2        Diff
STAT...redo size                     2,840       2,964         124
STAT...session pga memory                0     196,608     196,608

Run1 latches total versus runs -- difference and pct
Run1        Run2        Diff       Pct
608,845     608,706        -139    100.02%

PL/SQL procedure successfully completed.

3) <b>is correct, weakly typed variables in general (any language) have this attribute</b>.  strongly types variables catch more "errors" at compile time.  Consider:

ops$tkyte@ORA10GR2> create or replace procedure weak_demo
  2  as
  3          x       types.weak;
  4          l_rec all_users%rowtype;
  5  begin
  6          open x for select * from all_objects;
  7          fetch x into l_rec;
  8          close x;
  9  end;
 10  /

Procedure created.

ops$tkyte@ORA10GR2> exec weak_demo
BEGIN weak_demo; END;

*
ERROR at line 1:
ORA-06504: PL/SQL: Return types of Result Set variables or query do not match
ORA-06512: at "OPS$TKYTE.WEAK_DEMO", line 7
ORA-06512: at line 1


ops$tkyte@ORA10GR2> create or replace procedure strong_demo
  2  as
  3          x       types.strong;
  4          l_rec all_users%rowtype;
  5  begin
  6          open x for select * from all_objects;
  7          fetch x into l_rec;
  8          close x;
  9  end;
 10  /

Warning: Procedure created with compilation errors.

ops$tkyte@ORA10GR2> show errors
Errors for PROCEDURE STRONG_DEMO:

LINE/COL ERROR
-------- -----------------------------------------------------------------
7/2      PL/SQL: SQL Statement ignored
7/2      PLS-00394: wrong number of values in the INTO list of a FETCH
         statement

<b>note that "weak" compiled - but does not run.  "strong" won't even compile as the compiler can "tell" 'this will never work'</b>


4) <b>does not apply, it is just false</b>

5) <b>is true as demonstrated above</b>.  The key is "COMPATIBLE" - it need not be IDENTICAL.  you can fetch a date/number column into a varchar2 - assuming it is long enough...


--------------------------------------------------------------------
question 2

The answer is ambigous.  Subjective.  I would say that technically <b>NONE OF THEM MAKE YOU USE A REF CURSOR</b>.  You might choose to do so - but it is not mandatory.

If the question were "which of the following scenarios would likely cause you to <b>consider</b> using a ref cursor" - my answer would be:

a, b, c, e

If the question is "which of the following scenarios make you use a ref cursor", the answer is:

<this space intentionally left blank>


a) I could just as easily use a VIEW.  A ref cursor could well be useful.  (a) could be choosen.

b) I might use a ref cursor, I might use dbms_sql.  (b) could be choosen (surprising you say (b) was not an answer??)

   l_query := 'select ' || p_columns_passed_in || ' from t where ...';
   open l_cursor for l_query;


c) I might use a ref cursor, I might use decode - say I wanted to order by any of columns C1, C2, C3

   for x in ( select * from t where .... 
              order by decode( p_order_by, 1, c1 ), 
                       decode( p_order_by, 2, c2 ),
                       decode( p_order_by, 3, c3 ) )
   loop

or I could:

  open l_cursor for 'select * from t where ... order by c' || p_order_by;

or I could:

   if ( p_order_by = 1 ) then
        open l_cursor for select * from t where ... order by c1;
   elsif ( p_order_by = 2 ) then
        open l_cursor for select * from t where ... order by c2;
  ......

C may or may not be choosen.

d) I don't see how D applies here.  D is not one of my choices.

e) E could certainly apply!!  You can dynamically construct a query and open it using a ref cursor.

http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:1288401763279


So, I believe this test to be "not such a good one" if they picked the answers you say they did. 

Reuse of cursors

Jenny, March 23, 2006 - 4:03 am UTC

Hello Tom,

I need to iterate over two ref cursor, one loop inside the other. My problem is that I don't know how to reuse the second cursor in PL/SQL. Right now I'm fetching it again, a very time consuming query. Can I repoint cur2 instead of closing it and reopening it=

Could you please help me?

--cur1 and cur2 are ref cursors
cur1 := getFirstCursor;

--iterate over first cursor
loop
fetch cur1 into var1;
exit when cur1%NOTFOUND;

--Always the same result from
--getSecondCursor for the same
--var1 data
cur2 := getSecondCursor (var1);
loop
--do stuff with data from cur1 and cur2
exit when cur2%NOTFOUND;
end loop;
close cur2;

end loop;
close cur1;

I've simplified the procedure, I hope I haven't left out something important.



Tom Kyte
March 23, 2006 - 10:50 am UTC

the second cursor seems to be parameterized by the output of the first (var1).

So, the second cursor is NOT being "reused", it likely returns different data each and every time!


But the answer here is clear - you didn't mean to use getFirstCursor or getSecondCursor

You meant to use "getMeTheBestCursor" which "just joins" - you would never do what you are doing - unless you work for a hardware manufacturer and wanted to sell lots more hardware.

You do NOT want to do the functional equivalent of:

for x in ( select * from t1 )
loop
for y in ( select * from t1 where t2.fkey = x.key )
loop
process...


You want to simply do:

for x in ( select * from t1, t2 where t1.key = t2.fkey )
loop
....


JUST JOIN.

reuse of cursor

Jenny, March 23, 2006 - 5:17 am UTC

An error in the above: getSecondCursor returns the same result independent of any data from cur1. Otherwise it wouldn't be possible to reuse cur2, of course.

Sorry about that

Tom Kyte
March 23, 2006 - 10:56 am UTC

just join.

just join.

just JOIN. it is what databases do BEST.


There are plsql tables (like arrays), but I would vote for just join first and foremost, you didn't mean to do two queries


ORA-00932: inconsistent datatypes: expected UDT got CHAR

Hitesh Bajaj, March 24, 2006 - 1:01 pm UTC

Hi Tom,

Please help me to resolve the error as I have been struggling to overcome this for quite some time.


Create or replace procedure AWR_REPORT AS
begin
declare
min_snap number;
next_snap number;
myval_sequence number;
Path VARCHAR2(100) ;
filename VARCHAR2(100) := 'Awr_report.txt';
report_filename VARCHAR2(100);
err_num NUMBER;
err_msg VARCHAR2(500);
Output_file utl_file.file_type;
p_dbid NUMBER;
p_instance_number NUMBER;
p_report_options NUMBER := 8;
awr_output AWRRPT_HTML_TYPE_TABLE;
begin
begin
Select value into path from v$parameter where name = 'utl_file_dir';
output_file := utl_file.fopen (path,filename, 'a');
snap_file := utl_file.fopen (path,snapfilename, 'a');

EXCEPTION
When NO_DATA_FOUND then
err_num := SQLCODE;
err_msg := Substr(SQLERRM,1,500);
if (err_msg = 'ORA-01403: no data found') then
err_msg := 'Grant Privilege on V$parameter missing to the Schema Owner';
end if;
utl_file.put_line (output_file,'Date : ' || to_Char(sysdate,'dd/mm/yyyy hh24:mi:ss') || ' Error generated while creating and opening a file with an error message ' || err_msg);
utl_file.fclose(output_file);
return;
end;
begin
for x in (
Select snap_id,dbid,instance_number from dba_hist_snapshot where snap_id >
(1) order by snap_id) loop
If min_snap is NULL then
min_snap := x.snap_id;
else
next_snap := x.snap_id;
end if;
p_dbid := x.dbid;
p_instance_number := x.instance_number;
if min_snap is NOT NULL AND next_snap is NOT NULL then
exit;
end if;
end loop;

If min_snap is NOT NULL AND next_snap is NOT NULL then

report_fileName := Path ||'/'||min_snap||'_'||next_snap||'.lst';

Select output into awr_output from table(dbms_workload_repository.awr_report_html(p_dbid,p_instance_number,min_snap,next_snap,p_report_options));

utl_file.put_line (output_file,'Date : ' || to_Char(sysdate,'dd/mm/yyyy hh24:mi:ss') || ' AWR Report for the Snapshots ' || min_snap || '-' || next_snap || ' has been published.');
utl_file.fclose(output_file);
return;
else
utl_file.put_line (output_file,'Date : ' || to_Char(sysdate,'dd/mm/yyyy hh24:mi:ss') || ' Could not get the required snapshots to build the Statspack/awr-report ');
utl_file.fclose(output_file);
return;
end if;
end;
end;
end;
/

ERROR at line 1:
ORA-06512: at line 1
ORA-00932: inconsistent datatypes: expected UDT got CHAR
ORA-06512: at "SCOTT.AWR_REPORT", line 56
ORA-06512: at line 1

I even checked with making the string "Select output..." a dynamic string and using execute immediate to execute it but the same error message appears.

Please help!

2) If the output gets generated as .html file it gets dumped in the $ORACLE_HOME/bin folder. Is there any way to get this file created an user defined destination folder.

Thanks in advance


Thanks
Hitesh Bajaj



Tom Kyte
March 24, 2006 - 4:09 pm UTC

well, I didn't even get THAT FAR. since this code doesn't have snap_file and snapfilename declared.

So, I declare them, figure out I need to grant on dbms_workload_repository and such (test cases = small, concise, yet 100% complete. Debugging is straight forward, the first goal is to whittle the problem down to the bare bones).



that table function is using a table of strings, meaning, each row it returns will return A STRING. You need to LOOP OVER it and retrieve STRINGS. It does NOT return a collection.



for x in (Select output from
table(dbms_workload_repository.awr_report_html(p_dbid,p_instance_number,min_snap,
next_snap,p_report_options)) )
loop
-- process here;
null;
end loop;


You will have the STRINGS x.output in the loop




It did work out.

Hitesh Bajaj, March 26, 2006 - 6:58 am UTC

Hi Tom,

Thanks a lot as it finally worked out based on your suggestions. Now the file AWR_REPORT_2309_2310.html is getting created at the desired location by executing the procedure:

Create or replace procedure AWR_REPORT AS
begin
declare
min_snap number;
next_snap number;
myval_sequence number;

Path VARCHAR2(100) ;
filename VARCHAR2(100) := 'Awr_report.txt';
Output_file utl_file.file_type;

report_filename VARCHAR2(100);
report_output utl_file.file_type;

err_num NUMBER;
err_msg VARCHAR2(500);
p_dbid NUMBER;
p_instance_number NUMBER;
p_report_options NUMBER := 8;

begin
begin
Select value into path from v$parameter where name = 'utl_file_dir';
output_file := utl_file.fopen (path,filename, 'a');

EXCEPTION
When NO_DATA_FOUND then
err_num := SQLCODE;
err_msg := Substr(SQLERRM,1,500);
if (err_msg = 'ORA-01403: no data found') then
err_msg := 'Grant Privilege on V$parameter missing to the Schema Owner';
end if;
utl_file.put_line (output_file,'Date : ' || to_Char(sysdate,'dd/mm/yyyy hh24:mi:ss') || ' Error generated while creating and opening a file with an error message ' || err_msg);
utl_file.fclose(output_file);
return;
end;

begin
for x in (
Select snap_id,dbid,instance_number from dba_hist_snapshot where snap_id >
(Select NVL(MAX(end_snap_id),0) from perf_log_analysis) order by snap_id) loop
If min_snap is NULL then
min_snap := x.snap_id;
else
next_snap := x.snap_id;
end if;
p_dbid := x.dbid;
p_instance_number := x.instance_number;
if min_snap is NOT NULL AND next_snap is NOT NULL then
exit;
end if;
end loop;

If min_snap is NOT NULL AND next_snap is NOT NULL then

Select monitoring_seq.nextval into myval_sequence from dual;
report_fileName := 'AWR_REPORT_' || min_snap||'_'||next_snap||'.html';
report_output := utl_file.fopen (path,report_filename,'a');

for y in (Select output from table(dbms_workload_repository.awr_report_html(p_dbid,p_instance_number,min_snap,next_snap,p_report_options))) loop
utl_file.put_line(report_output,y.output);
end loop;

Insert into perf_log_analysis Values (myval_sequence,min_snap,next_snap,sysdate,Path || '/' || report_fileName,'Y');
commit;
utl_file.fclose(report_output);
utl_file.put_line (output_file,'Date : ' || to_Char(sysdate,'dd/mm/yyyy hh24:mi:ss') || ' AWR Report for the Snapshots ' || min_snap || '-' || next_snap || ' has been published.');
utl_file.fclose(output_file);
return;
else
utl_file.put_line (output_file,'Date : ' || to_Char(sysdate,'dd/mm/yyyy hh24:mi:ss') || ' Could not get the required snapshots to build the Statspack/awr-report ');
utl_file.fclose(output_file);
return;
end if;
end;
end;
end;
/

Tom, please help me in getting this file e-mailed to me as an attachment or in the desired HTML format. Is the procedure mentioned at your site using </code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:1739411218448 <code>

will work, but I am confused as it is not taking any input as filename.

Please help!




Tom Kyte
March 26, 2006 - 8:32 am UTC

that shows exactly how to email html as the email body??? Not sure what more you would need.

Please help

Hitesh Bajaj, March 28, 2006 - 10:29 am UTC

Hi tom,

The procedure mentioed above creates a file whose extension is .html

This is the AWR report which normally gets generated when we choose the type of content to be HTML across two snapshots. Now this file is dumpled under the directory mentioned by UTL_FILE.

Now I want the contents of the file to be mailed as HTML body or could be as an attatchment.

I had looked at the procedure but am not sure where to pass the contents of the file, to the IN parameters.

Can you please help me a bit more, since I am new to PL/SQL stuff.

Thanks in advance!

Tom Kyte
March 28, 2006 - 4:11 pm UTC

don't write it to the file system - use the sending of html email as it was programmed and supplied for you

or, write it yourself.

How to use SYS_CONTEXT when you have a local variable besides procedure parameters?

Sinan Topuz, April 12, 2006 - 5:49 pm UTC

Tom,

I have the following sample tables and a procedure and I am trying to use BIND variables here.

create table dept( dept_code varchar2(10)
, dept_name varchar2(50) );

create table country (cnt_code varchar2(10)
,cnt_name varchar2(50) );

create table emp (emp_code varchar2(10)
,emp_name varchar2(30)
,status varchar2(1) default 'A'
,dept_code varchar2(10)
,cnt_code varchar2(10)
,mgr_code varchar2(10) );

CREATE OR REPLACE PROCEDURE emp_list
(pdept in varchar2 DEFAULT NULL
,pmngr in varchar2 DEFAULT NULL)
is

l_str varchar2(1000);

TYPE cv_typ IS REF CURSOR;
cv cv_typ;

BEGIN

FOR cr_country in (SELECT cnt_code
, cnt_name
FROM country )
LOOP
l_str := 'SELECT emp_code, emp_name FROM emp WHERE status = ''A'' ';
-- IF pdept IS NOT NULL THEN
l_str := l_str || ' AND dept_code = :b_dept ';
-- END IF;
-- IF pmngr IS NOT NULL THEN
l_str := l_str || ' AND mngr_code = :b_mngr ';
-- END IF;
l_str := l_str || ' AND cnt_code = :b_cnt ';
LOOP
OPEN cv FOR l_str
USING pdept, pmngr, cr_country.cnt_code ;
/* When I uncomment the lines things started to get interesting. Without trying to figure out the combinations of IF statements that I could use while opening the REF_CUROSRHHow would I determine what I will put after USING clause with SYS_CONTEXT?
There is a special case here (at least for me) that WHERE clause is also having a LOCAL variable "cr_country.cnt_code".
Is it possible to use bind variables here? I looked at the SYS_CONTEXT discussions, but I as far as I have read I could not
see any example including a local variable in the WHERE clause.
*/
EXIT WHEN cv%NOTFOUND;
-- will do something here
NULL;
END LOOP;
CLOSE cv;

END LOOP;

EXCEPTION WHEN OTHERS THEN
CLOSE cv;
END;

Thanks for your time and help in advance!

Thanks Tom. I tried the solution and it worked well.

Sinan Topuz, April 17, 2006 - 5:56 pm UTC


A reader, April 20, 2006 - 5:39 pm UTC

Tom,

Whats the difference between just spooling a file by doing a simple select x,y,z joining four tables and doing the same using a cursor, looping around and printing them into the file? I am sure the cursor is not necessary.

Tom Kyte
April 21, 2006 - 7:09 am UTC

not only not necessary, but a ton of code with lots of potential bugs.

that, and it'll run slower in all probability (than spool) unless you use a nice fast truly compiled language (like C) and good bulk fetch sizes.

but don't write your own:

</code> http://asktom.oracle.com/~tkyte/flat/index.html <code>




query

raj, April 21, 2006 - 1:17 pm UTC

Tom,

How to find out " minimum value of column 1 for each value of column2 "?
I am scratching my head too...appreciate if you help me out

Tom Kyte
April 21, 2006 - 3:30 pm UTC

sounds like

select min(c1), c2 from t group by c2

doesn't it.

Ram, April 21, 2006 - 5:07 pm UTC

Reviewer: William from Ontario Canada

This is really helpful and handy too. But I would like to know the advantage of
using context over building the predicate dynamically eg.

l_query := l_query || ' and empname like '''||p_ename||'''';

Thanks




Followup:
Get my book -- its all about bind variables.

Bind variables are SO crucial, so important -- you MUST use them.

If you do something like:

for i in 1 .. 1000
loop
execute immediate 'insert into t values ( ' || i || ')';
end loop;

90%, yes 90%, of your time will be spent parsing. If you on the other hand:

execute immediate 'insert into t values ( :x )' using I;

you will spend a significantly less amount of time parsing. And if you just:

insert into t values ( i );

you'll spend almost NO time.


Parsing (soft and hard) latches the library cache. A latch is a lock by any
other name. You are serializing operations by over parsing. it will limit your
scalability, decrease your performance and you will FAIL if you do not use bind
variables!
--------------------------------------
Hi Tom,
I agree with parsing over load. But in case where there are NO inserts
meaning simple select... with different where clause...may vary depending on input values
to stored proc. would it not be efficient to use "execute immediate".

thanks
Ram
Harrsiburg, PA








Tom Kyte
April 21, 2006 - 5:24 pm UTC

I don't care if you do insert, delete, update, select, merge - they are all JUST SQL

SQL is SQL
a hard parse is very very very bad
a soft parse on the other hand is just very very bad.


execute immediate isn't what you mean, I think you meant "open" to dynamically open a ref cursor


(you should have seen this coming since the entire example for the original question was about a SELECT!)

Conditional Cursors

Mark, April 25, 2006 - 10:42 am UTC

Hi Tom,

Oracle 8.1.7.4 STANDARD

What is the best way to do conditional cursors?

What I mean is, I have two cursors - a, b. I want to use an input or lookup value to decide which one I open.

I need the cursor naming and record var naming to be the same so the rest of the code works as written.

The difference between the two cursors is one column that is grouped upon.

Otherwise, the code runs exactly the same.

Sort of like this (but this does not work):

If v_choice = 'N' then
OPEN a(v_in);

Else
OPEN b(v_in);
End if;
loop
FETCH a into rec;
EXIT when a%notfound;
.
. DO WORK
.
END lOOP a;
CLOSE a;

This obviously does not work because my FETCH, EXIT, END LOOP and CLOSE reference 'a' cursor, and would fail if v_choice = 'Y', indicating to use 'b' cursor.

I'd really just like to swap out the cursors right at the beginning so the rest of the code flows.

Any ideas?

Trying to avoid dynamic SQL also.

Thanks in advance and truly a great resource here.

Tom Kyte
April 25, 2006 - 10:58 am UTC

read about ref cursors.

if ( condition )
then
open ref_cursor for select ...
else
open ref_cursor for select something else ...
end if;

loop
fetch ref_cursor into rec;
exit when ref_cursor%notfound;
....

Conditional Cursors

Mark, April 25, 2006 - 4:39 pm UTC

Perfect! Thanks!



Search on complex model

Faisal, May 03, 2006 - 5:54 am UTC

Hi Tom,

I have to provide a search capability to my users. The data model consist of 25 tables (Fully Normalized). In normal situation, we query from top-bottom for example, select parent and all its related child records. I have to develope a complex query mechanisum where user almost can search any information even, bottom-to-top. So far I have created views in order to denormailze the information. What should be my approch here?

Tom Kyte
May 03, 2006 - 7:07 am UTC

</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:5533095920114 <code>

that shows how I do something very similar here on asktom.

difference between dbms_application_info.set_client_info and dbms_session.set_context

A reader, May 08, 2006 - 1:39 pm UTC

Tom, can you give me basic difference between dbms_application_info.set_client_info and dbms_session.set_context? I was told both can be used for same purpose [passing parameters and bind them to query, dynamically for different sessions]

If so, why we need to use dbms_session.set_context over other [dbms_application..]

Thanks,

Tom Kyte
May 08, 2006 - 1:40 pm UTC

set client info may set one string into the column client_info in v$session.

that string is 64 characters long and there is ONE of them.


set context can set many more strings in a private namespace.
and the strings can be longer.

setting NULL in set_context

Rajeswari, May 24, 2006 - 9:15 am UTC

Tom,

I am using syscontext in the view. I used NVL to display all the records from the table - only for testing not in real. Used bold only to highlight.

Why it is not returning any records if I set NULL value to the context?


create table emp(empno number,empname varchar2(30), jdt date);
alter table emp add constraint emp_pk primary key(empno);


insert into emp values(1001,'User1',sysdate);
insert into emp values(1002,'User2',sysdate-45);
insert into emp values(1003,'User3',sysdate-145);
insert into emp values(1004,'User4',sysdate-345);
commit;


scott@ORA9.2> select * from emp;

EMPNO EMPNAME JDT
---------- ------------------------------ ---------
1001 User1 24-MAY-06
1002 User2 09-APR-06
1003 User3 30-DEC-05
1004 User4 13-JUN-05



create context empctx using emppkg;

create or replace package emppkg as

type refcur is ref cursor;

procedure emplist(emp_joining_dt in date, cemp out refcur);

end;
/

create or replace package body emppkg as
procedure emplist(emp_joining_dt date,cemp out refcur) as
begin
dbms_session.set_context('EMPCTX','JOINING_DT',emp_joining_dt);

if (sys_context('EMPCTX','JOINING_DT') IS NULL) THEN
dbms_output.put_line('Context is null');
END IF;

open cemp for select empno,empname,jdt from empview;

end emplist;
end;
/


create or replace view empview as
select empno,empname,jdt from emp
where jdt <= NVL(sys_context('EMPCTX','JOINING_DT'),jdt)
/


scott@ORA9.2> var ret refcursor
scott@ORA9.2> exec emppkg.emplist(sysdate,:ret);

PL/SQL procedure successfully completed.

scott@ORA9.2> print :ret

EMPNO EMPNAME JDT
---------- ------------------------------ ---------
1002 User2 09-APR-06
1003 User3 30-DEC-05
1004 User4 13-JUN-05



scott@ORA9.2> exec emppkg.emplist(null,:ret);
Context is null
EMPCTX.JOINING_DT =

PL/SQL procedure successfully completed.

scott@ORA9.2> print :ret

no rows selected

scott@ORA9.2> select empno,empname,jdt from emp
2 where jdt <= NVL(null,jdt);

EMPNO EMPNAME JDT
---------- ------------------------------ ---------
1001 User1 24-MAY-06
1002 User2 09-APR-06
1003 User3 30-DEC-05
1004 User4 13-JUN-05


Tom Kyte
May 25, 2006 - 6:57 am UTC

implicit conversion.  did you note the care I took to avoid them in the example above??

nvl( STRING, DATE )

is really

nvl( STRING, to_char(DATE) );


and when you

where jdt <= nvl( STRING, to_char(DATE) )

it will really be:

where jdt <= to_date( nvl(STRING, to_char(DATE,'dd-mon-rr')), 'dd-mon-rr' ) 


assuming the default date mask....  hence, you are having an implicit conversion take place, stripping off the TIME component and none of the jdt's are as of midnight (unless you run the example at midnight), so none of them are less than or equal to midnight.

ops$tkyte@ORA10GR2> create or replace package body emppkg as
  2      procedure emplist(emp_joining_dt date,cemp out refcur) as
  3      begin
  4        <b>dbms_session.set_context('EMPCTX','JOINING_DT',to_char(emp_joining_dt,'yyyymmddhh24miss'));
  5</b>
  6        if (sys_context('EMPCTX','JOINING_DT') IS NULL) THEN
  7          dbms_output.put_line('Context is null');
  8        END IF;
  9
 10        open cemp for select empno,empname,jdt from empview;
 11
 12      end emplist;
 13  end;
 14  /

Package body created.

ops$tkyte@ORA10GR2>
ops$tkyte@ORA10GR2>
ops$tkyte@ORA10GR2> create or replace view empview as
  2   select empno,empname,jdt ,
  3                NVL(sys_context('EMPCTX','JOINING_DT'),jdt) sctx
  4     from emp<b>
  5   where jdt <= to_date( NVL(sys_context('EMPCTX','JOINING_DT'),
  6                         to_char(jdt,'yyyymmddhh24miss')), 'yyyymmddhh24miss' )</b>
  7  /

View created.

 

Function Returning Multiple Values

Surendra, May 25, 2006 - 2:38 am UTC

Dear Tom,

Thanks for all the wonderful answers.

Consider folllowing situation where I want to return multiple values from a function.

CREATE OR REPLACE TYPE CALCType AS OBJECT
(
VAL1 BINARY_FLOAT
, VAL2 BINARY_FLOAT
, VAL3 BINARY_FLOAT
, VAL4 BINARY_FLOAT
, VAL5 BINARY_FLOAT
)
/

CREATE OR REPLACE FUNCTION CALC (
ID VARCHAR2
) RETURN CALCType
IS
L_VAL1 BINARY_FLOAT;
L_VAL2 BINARY_FLOAT;
L_VAL3 BINARY_FLOAT;
L_VAL4 BINARY_FLOAT;
L_VAL5 BINARY_FLOAT;
BEGIN
L_VAL1 := 111.56;
L_VAL2 := 222.56;
L_VAL3 := 333.56;
L_VAL4 := 444.56;
L_VAL5 := 555.56;

RETURN CALCType(L_VAL1, L_VAL2, L_VAL3, L_VAL4, L_VAL5);

END CALC;
/

I can receive individual values as
SELECT CALC('1').VAL1, CALC('1').VAL2,CALC('1').VAL3, CALC('1').VAL4, CALC('1').VAL5 FROM DUAL;

However it may execute the function those many times.
Is it any way where I execute the function only once and still get individual values?

The function is required to be called in a Query along with other columns.

OR any other way to achive this?

Regards,


Tom Kyte
May 25, 2006 - 1:40 pm UTC

....

 16
 17      dbms_application_info.set_client_info( userenv('client_info')+1 );
 18      RETURN  CALCType(L_VAL1, L_VAL2, L_VAL3, L_VAL4, L_VAL5);
 19
 20  END CALC;
 21  /

Function created.

ops$tkyte@ORA10GR2> exec dbms_application_info.set_client_info(0);

PL/SQL procedure successfully completed.

ops$tkyte@ORA10GR2> select x.data.val1, x.data.val2, x.data.val3, x.data.val4, x.data.val5
  2    from (select (select calc('1') from dual) data from dual) x
  3  /

 DATA.VAL1  DATA.VAL2  DATA.VAL3  DATA.VAL4  DATA.VAL5
---------- ---------- ---------- ---------- ----------
1.116E+002 2.226E+002 3.336E+002 4.446E+002 5.556E+002

ops$tkyte@ORA10GR2> select userenv('client_info') from dual;

USERENV('CLIENT_INFO')
----------------------------------------------------------------
1

ops$tkyte@ORA10GR2> SELECT CALC('1').VAL1, CALC('1').VAL2,CALC('1').VAL3, CALC('1').VAL4,
  2  CALC('1').VAL5 FROM DUAL;

CALC('1').VAL1 CALC('1').VAL2 CALC('1').VAL3 CALC('1').VAL4 CALC('1').VAL5
-------------- -------------- -------------- -------------- --------------
    1.116E+002     2.226E+002     3.336E+002     4.446E+002     5.556E+002

ops$tkyte@ORA10GR2> select userenv('client_info') from dual;

USERENV('CLIENT_INFO')
----------------------------------------------------------------
6
 

setting NULL in set_context

Rajeswari, May 30, 2006 - 4:48 am UTC

Thanks a lot Tom for reminding about implicit conversion. I seen your syscontext example with the explicit conversion for date but somehow it slipped from my mind when I tested with NULL value.

Thank you again for detail clarification.

PL?SQL STORED PROCEDURES

balu, June 03, 2006 - 2:27 am UTC

can any one please send me EXAMPLES OF "PL/SQL STORED PROCEDURES

,.....USING MULTIPLE CURSORS WITH PARAMETERS PASSING"
......................................................................................................................
and ......... EXAMPLES FOR PL/SQL STORED PROCEDURE

USING TWO CURSORS WITH ONE PARAMETER PASSING



Tom Kyte
June 03, 2006 - 8:43 am UTC

something wrong with your keyboard?

There is nothing special, magic, or unqiue about "using more than one cursor and passing parameters". In fact, that is very "basic"

create procedure p( p_x in number, p_y in number )
as
begin
for c1 in (select * from t where x = p_x)
loop
...
end loop;
for c2 in (select * from t where y = p_y)
loop
...
end loop;
end;
/

you can certainly take that and make it be "two cursors with one parameter" I hope..

Reference Cusor

Tim, June 12, 2006 - 12:58 pm UTC

Your example at the top of this thread was very helpful in allowing me to get this working. The Oracle docs are very detailed - but just were not pushing me in the right direction. Your example was just what I needed. Thanks.

The reason I want to use this technique is my client/server application uses a query window where the user can choose which fields to enter. Currently - this means the client application is dynamically creating the SQL statement and including the user selected parameters as strings - ie - no bind variables - each SQL issued (most likely) different from every other SQL. As an additional side benefit - it will also be great to get the SQL on the server rather than on the client - as our client application gets pushed out to thousands of users across the country - so when we have to "tweak" some SQL - the change is easy - but getting the change to the users is hard. When we get the SQL on the server - we will be able to push the change into production much easier.

Now, using the examples you have provided, I can (slowly) convert this over to putting the SQL in a packaged procedure (in an Oracle 9.2.0.4 server) using a reference cursor and making use of the SYS_CONTEXT technique to input the appropriate user chosen values. I would now expect a limited number of unique SQL statements. As you had pointed out - we will not get the mathematically maximum number of combinations/permutations (whatever) because users tend to have similar needs and in reality will be mostly choosing similar types of fields to query on.

Hence my question. We have done user activity monitoring and can show (using one particular query window as an example) that about 80% of the time - the users are actually performing two queries (distinct sets of criteria fields chosen). So, although the technique we can now use will support this - I am wondering about the "soft parse" aspect of the PLSQL executed dynamic query. I am not clear on "how bad" is the soft parse - which if I understand what you have written above - will occur for each invocation of the dynamic SQL - no caching possible - soft parse each time.

Would it be worth our while to code a conditional in the packaged procedure such that if we see the fields coming in which match one of the two queries (which our monitoring shows is 80% of the time) - we branch to logic which executes one of two non-dynamic sql using binds. The rest of the time - we go to the dynamic SQL using the sys_context - which would cover all of the other possibilities.

Or - at this point (where many queries are not using binds) - would I be going after a fine point and missing the larger point? ie - Should I at this time concentrate on converting the "old-style" queries which are dynamic client-based and not using binds - to using server-based packaged procedures using dynamic SQL with sys_context for variable substitution - and at this time not worry about the "soft parse". Then after all of this is converted over - then go back and pull the most common queries into separate conditional logic which would use non-dynamic SQL with binds? Or even at that point - would this still be too fine of a detail to bother with?

To add another wrinkle - we have two applications which are both using a single Oracle instance. I am working on one application which is an in-house client/server application - we have control over this and can (within reason) do what we want. The other application (PeopleSoft financials v8.8) is a 4-tier application which we are quite restricted in what can be done - both from a technical point of view and from a business decision point of view. Currently neither of these use binds (from what our DBA has told me - I can only verify the app I work on) for the query windows in which the user has a selection of fields from which to base their query on. So - by fixing the one application - how much will that really help us if the other application is still not using binds? Is that a case where we should perhaps consider fixing the application we can - and perhaps using "cursor_sharing = force" for the other application? Other application being n-tier uses connection pooling such that all connections come into the Oracle database under a single user name - maybe a system logon trigger looking for that particular user name would alter the session and force the cursors to match?


Tom Kyte
June 13, 2006 - 10:43 am UTC

if you are using a ref cursor - ref cursors are always parsed upon open - regardless of whether they are "static" or "dynamic"

the reason - you can call this procedure 50 times, get 50 cursors and have them all open simultaneously - they are all just "pointers to separate cursor work areas"

so, static or dynamic - a ref cursor is going to cause a parse.

things that I want to know about cursors, to write a better tuned code

Ravi, June 21, 2006 - 4:28 pm UTC

1)how does it keep track of which record to be shown next
2)does the query in the cursor gets executed for each fetched row
3)if it is executed once for each record that it returns
does query waits until it finds the
entire result set and returns the next record
of the previously returned record
4)how does it work when we use BILK COLLECT

can you please explain the above, this will help me a lot in writing a better code


Tom Kyte
June 22, 2006 - 11:44 am UTC

suggest you get access to "Effective Oracle by Design" if you can as I spent many many pages on stuff just like this in chapters on "effective sql" and "effective plsql"

it is bigger than a breadbox - a cursor is just a pointer to a result set, result sets are processed in MANY different ways.

utility of clause where 1 = 1

A reader, June 27, 2006 - 10:49 am UTC

Dear Tom,

I am sure that I have read in asktom site something about the utility or not in using where 1 = 1 in a query. Unfortunately I didn't find it.

Could you please let me know in few words if it is recommended to add a where clause like
where 1 = 1.

Franckly speaking, I see no interests.

Thanks in advance

Tom Kyte
June 27, 2006 - 11:07 am UTC

it is handy in dynamic sql sometimes. So you don't have to remember if you should be using "where" or "and" to combine predicates - you always just use "and" since the where is already there.

see
</code> http://asktom.oracle.com/pls/asktom/f?p=100:11:::::P11_QUESTION_ID:1288401763279 <code>
for example

Line Number

Mark, July 05, 2006 - 10:47 am UTC

Hi Tom,

Does oracle expose to the environment what line number it is executing in pl/sql code?

I'd like to use it in debugging with dbms_application_info calls...otherwise, I have to explicitly enter the number.

Regards,
Mark

Tom Kyte
July 08, 2006 - 8:00 am UTC

Re: Above (Mark)

Matthew Lange, July 06, 2006 - 3:41 pm UTC

Hi Mark,

IIRC, you can find what query is being run, but after that I'm not sure.

You can check certain oracle views to determine the hash of the statement being run, then you can join that with another view to determine which statement is being run.

I believe I read that on oracle.com.

FOR x IN dynamic sql

Branka, July 18, 2006 - 5:13 pm UTC

Can I pass dinamyc select into statement
FOR x IN (dynamic_select)
LOOP
BEGIN
SELECT APPLICATION_SERIAL_NUMBER into v_app
FROM APPLICATION
WHERE rowid = x.rid
FOR UPDATE nowait;
exit;
exception
when RESOUCE_BUSY then
null;
end;
end loop;

Tom Kyte
July 19, 2006 - 8:57 am UTC

no, dynamic sql mandates the use of explicit cursors via "open", "fetch" and "close"

FOR x IN dynamic sql

Branka, July 20, 2006 - 7:31 am UTC

Thank you.

Dynamic SQL for Workflow processing

partha, July 20, 2006 - 6:16 pm UTC

Background:
The application allows for the user to define the processing / triggering of activities. Let's say for example the dept and emp and loc tables. The screen looks like:

Columns: XXXXXXXXX Condition: XXXXX Value: XXXXXXXXXX
Action: XXXXXXXXXXXXXXXXXXXXXXX Action Value: XXXXXXXXX

Columns will have all the columns from dept and emp
Conditions is a select list, "=", "<>", "LIKE" etc.
Value: is either from a select for = and <> and a free text for LIKE
Action: is from a select list like, "Change Department to", "Change Manager" etc, and Action Value could be either from a select list or a free text.

This will allow the user to put in any kind of processing.

Current Solution:
For the conditions processing, I store the values for the columns || conditions || value and stored it in a table called "where condition", had a function which used a dynamic sql and concatenated the "where condition" and return a value of true or false, based on that executed one more dynamic sql which did the "action processing" which is equivalent to some update statements.

Issue:
This leads to the issue of not using bind variables and sql injection. because the condition processing was a simple concatenation. "select 1 from emp a, dept b where a.deptno = b.deptno" || where_condition_from_table ;

Proposed Alternate:
To use sys_context and set the values as mentioned in the example at the beginning of the page, while storing the condition processing and store that as the where_condition in the table and then concatenate the where condition in the dynamic sql. For example, If the condition selected is:

Columns: "DEPTNO" condition: "=" value: "10"
Then create the where condition as

if mv_columns="DEPTNO" then
mv_where := mv_where || ' and deptno ' || condition_from_table || '
sys_context( ''MY_CTX'', '' || value_from_table
|| ''' ) ';
elsif mv_columns="DNAME" then
mv_where := mv_where || ' and dname = ' || condition_from_table || '
sys_context( ''MY_CTX'', '' || value_from_table
|| ''' ) ';
end if ;

Question:
(a) Is this approach correct
(b) Will this eliminate the possibility of sql injection and use bind variables
(c) Is there an alternate way to do the above ?

ps:
Not sure if this belongs to a separate question or is part of a followup / clarification, if it needs to be asked when you are taking up new questions, ignore it and I will raise it as a separate question later. Thanks

Tom Kyte
July 22, 2006 - 5:30 pm UTC

condition_from _table is subject to sql injection still - ANYTIME you concatenate in user supplied data and compile it - you are subject to that.

have you considered using the workflow package that comes with the database? I mean - you already "own" workflow? it comes with...

Partha, July 22, 2006 - 11:51 pm UTC

Sorry, should have been more clear. The value_from_table and condition_from_table is basically my code which is calculated based conditions selected through a select list.

In my user screen I have: Select condition: <Is / Is Not / Begins with / Does not Begin with>

case (condition)
when 'Is' then
condition_into_table := ' = ' ;
when 'Is Not' then
condition_into_table := ' <> ' ;
when 'Begins with' then
condition_into_table := ' LIKE '''%' || p_value_accepted || '%' || '''' ;
....
end case ;

I guess you mean that, p_value_accepted can be subject to sql injection? Will this still be a problem if it is wrapped through the sys_context? Is their any conventional solution for this issue. We are currently working on this and is in the design stage and haven't explored workflow yet. Since this is a small module and was required fast, not sure if we will go to workflow immediately but I'll have a look. Would appreciate if you can let me know any other way. Thanks

Tom Kyte
July 23, 2006 - 8:57 am UTC

anything the end user gives you that you DO NOT BIND is subject to sql injection.

That sort of defines the problem space, look as what you are doing and ask yourself "am I binding the user input or am I concatenating the user input into the string"

If you are concatenating, you have sql injection worries.

sys_context is a method of binding, if you pop the user input into sys_context it is "bound"

"was required fast" - laughing out loud. You decided writing, debugging and maintaining code was going to be "fast".




Ref Cursor

Anil Sapra, August 02, 2006 - 9:14 am UTC

Hi Tom,

I want to know is it necessary to bound context with any
procedure, can we use a single context i.e. MY_CTX with
many procedures...

As per your example at the top of this thread...

ops$tkyte@ORA8I.WORLD> create or replace context MY_CTX using MY_PROCEDURE
2 /

Context created.

That created our application context and bound it to our yet to be created
procedure "MY_PROCEDURE". Note that only MY_PROCEDURE will be able to set
values in this context.

My requirement is that I have to use this kind of scenario
in so many applications in which there may be so many procedures & functions
1 Should I use separate contexts for all or
2 single context can help me..

Pl. suggest on the above...

With regards,

Anil Sapra





Tom Kyte
August 02, 2006 - 12:03 pm UTC

it is bound to a procedure OR package....

it has to be.


Solution here seems rather simple. Write a procedure that sets a value in the context.

This procedure may not be called by all of your other code.

Instead of your other code calling dbms_session.set_context, it just calls your_function()

substituting parameter value for a table name

PAdmaja, August 15, 2006 - 2:00 pm UTC

Hi Tom,
I have a procedure that takes in parameter for a table name. Can you please tell me how to use this parameter in a select statement as a table name?
The code goes like this
create or replace procedure test1 ( var_tabname in char)
as
CURSOR var_cursor IS
SELECT * FROM tablename1;
begin
for var_rec in var_cursor loop
insert into tab2 (col1,col2)
values (var_rec.col1,var_rec.col2);
IF MOD(var_cursor%ROWCOUNT, 1000) = 0 THEN
COMMIT;
END IF;
end loop;
end test1;
/

I want to use var_tabname parameter value in the place of 'tablename1'. I am trying to implement this because tablename1 will the 11 servernames and instead of creating 11 procedures I can create one and pass parameter.

Thanks in Advance
Padmaja

If I posted this in wrong place please sagest where to post.

Tom Kyte
August 15, 2006 - 2:40 pm UTC

do they all have the same structure?

and why are you committing in the middle, what happens WHEN YOUR PROCEDURE FAILS HALFWAY THROUGH - hmmm, that could be a big problem no? How do you

a) back out that which you put in (perhaps after power is restored - so exceptions and such do not count)
b) restart in the middle, pick up where you left off???


this should be a single 'insert as select' - no procedural code!!!!!

great example of building dynamic where clause.

Vijay, October 03, 2006 - 5:34 am UTC

Dear Tom,
good day to you as always, this is a great example of building dynamic where clause for search, as you have mentioned the context can be bound to a procedure or a package, if bound to a package all the procedure of the package can use the context, has this changed in the new releases of Oracle here I mean creating something like a global context that can be used by any procedure/package.

your help in this regard is much appreciated.

Kind Regards,
Vijay

Tom Kyte
October 03, 2006 - 6:31 am UTC

a context is bound to a top level schema object which are

top level procedures (create procedure)
top level functions (create function)
packages

thanks for the help, but some more comments needed.

Vijay, October 03, 2006 - 6:49 am UTC

Dear Tom,
when you say top level schema object, procedure, function, package, does that means one context can be used only by the Package(function and procedures of package included), or the procedure or the function used to create the Context, please comment.

Thanks again for all your help.

Kind Regards,
Vijay

Tom Kyte
October 03, 2006 - 7:06 am UTC

create or replace context 'my_ctx' using SCHEMA.TOP_LEVEL_OBJECT;

that schema.top_level_object is allowed to set the values in the context my_ctx.

If top_level_object is a procedure or function ONLY that procedure or function may modify (set) the context values.

If top level objct is a package ANY procedure or function in that package may set it. The entire package is bound to it.

A context is bound to a SINGLE top_level_object and only that top_level object may modify it.

Thanks a lot for your help and time

Vijay, October 03, 2006 - 7:16 am UTC

Dear Tom,
Thanks a lot for all your help and time.

Kind Regards,
Vijay.

How to link more than one 1-to-many relationship could be handled in a single query?

Periasamy Subramaniyan, October 09, 2006 - 2:07 pm UTC

Say I have the following tables.

Works
id number
reference varchar2(20)

Works_contact
id number
works_id number
contact_name varchar2(100)

location
id number
works_id number
location_name varchar2(100)

service_action
id number
location_id number
service_name varchar2(100)

activity
id number
location_id number
activity_name varchar2(100)

I want a query, which returns,



works_id contact_name location_name service_name activity_name

123 Mr ABCD loc_134 ser_134_543 act_134_526
ser_134_546
123 MR XYZ loc_135 ser_135_578 act_135_746
act_135_789
124 loc_138 act_138_526

Relationship

Works --> workscontact 1 to many
works --> location 1 to many
location --> service_action 1 to many
location --> activity 1 to many

no other relationships defined.

Thanks and Regards
Periasamy

Tom Kyte
October 09, 2006 - 2:14 pm UTC

oh. i. love. questions. like. these.

laughing out loud.

say you have read a page, that begins with:

If your followup requires a response that might include a query, you had better supply very very simple create tables and insert statements. I cannot create a table and populate it for each and every question. The SMALLEST create table possible (no tablespaces, no schema names, just like I do in my examples for you)

Please limit this to a comment or question relevant to the other text on this page.

In order to permit NEW questions on this site, I am taking the firm stance that anything deemed a 'new question' asked here will be ignored.

Please think about what you are going to put into here and unless it is very relevant to the existing thread -- a true FOLLOWUP or REVIEW or CLARIFICATION, please do not post it.

This will allow me to accept new questions (I took 2,000 less in 2004 than 2003, but only because I followed up to 3,000 'reviews' that were actually new questions). This is by popular demand -- we need 'fresh blood' in there.


what would you say? :)


I really like this technique, but...

ChrisM, October 12, 2006 - 3:13 am UTC

Hi Tom,
Could you suggest how you would modify your example to handle the case when you actually want to search for a NULL value.

For example if having a NULL hiredate meant that an employee was on the system but had not commenced work, and you wanted to be able to modify my_procedure to return such records, how would you do it?

thanks

Tom Kyte
October 12, 2006 - 8:16 am UTC

25 if ( p_hiredate is NOT NULL ) then
26 dbms_session.set_context( 'MY_CTX', 'HIREDATE',
27 to_char(p_hiredate,'yyyymmddhh24miss'));
28 l_query := l_query ||
29 ' and hiredate >
30 to_date(
31 sys_context( ''MY_CTX'',
32 ''HIREDATE'' ),
33 ''yyyymmddhh24miss'') ';
else
l_query := l_query || ' and hiredate is null ';
34 end if;




want to analyze cusor and access it dynamically

Darin, October 17, 2006 - 3:14 pm UTC

Tom,

I want to be able to *analyze* a cursor, and access it's contents dynamically. Below is an example set of code for a process i run on multiple tables - each table has it's own implementation of the PL/SQL specific to the table.

create table src(a number, b varchar2(3), c varchar2(3));
create table dst(a number primary key, b varchar2(2), c varchar2(2));

insert into src(a, b, c) values(1,'a','a');
insert into src(a, b, c) values(1,'bb','bb');
insert into src(a, b, c) values(3,'ccc','ccc');
insert into src(a, b, c) values(4,'dd','ddd');
insert into src(a, b, c) values(5,'e','ee');
insert into src(a, b, c) values(6,'fff','f');


declare
cursor c1 is
select a,b,c from src;

dml_errors exception;
PRAGMA exception_init(dml_errors, -24381);

type t1 is table of src%rowtype;
v1 t1;

v_eC number := 0;
v_eI number := 0;
v_eCnt number := 0;
v_eCntTtl number := 0;

begin
open c1;
loop
FETCH c1 BULK COLLECT
into v1 LIMIT 5;
EXIT WHEN v1.count = 0;
/* DO SOME PROCESSING OF DATA HERE */
BEGIN
FORALL i in v1.first .. v1.last SAVE EXCEPTIONS
insert into dst values v1(i);
EXCEPTION
when dml_errors then
v_eCnt := SQL%BULK_EXCEPTIONS.COUNT;
if v_eCntTtl = 0 then
dbms_output.put_line(v_eCnt ||
' error(s) during insert into DST. Offending record(s) follow:');
else
-- errors already present, additional message...
dbms_output.put_line(' ' || v_eCnt || ' more error(s)...');
end if;
for i in 1 .. v_eCnt loop
v_eC := -SQL%BULK_EXCEPTIONS(i).ERROR_CODE;
v_eI := SQL%BULK_EXCEPTIONS(i).ERROR_INDEX;
v_eCntTtl := v_eCntTtl + 1;
dbms_output.put_line('..errCode='||v_eC||
'; errMsg='||SQLERRM(v_eC)||
'; [' || v_eCntTtl || ']:'||
' A=[' || v1(v_eI).A || ']'||
' B=[' || v1(v_eI).B || ']'||
' C=[' || v1(v_eI).C || ']');
end loop;
END;
-- commit; -- removed to avoid SNAPSHOT TOO OLD errors
EXIT WHEN c1%NOTFOUND;
end loop;
commit;
close c1;
end;
/

What I would like to do is take the code in the exception block (where I am reporting errors and data from the original array) and make it a generic procedure that I can call each time it is needed (i.e. for each table I am using this for). To achieve this, i cannot figure out a way to *analyze* the cursor - i.e. get the names of the columns in the cursor, then row bgy row step through each of those columns to generate the report of the failed rows.

Your isight is most appreciated, as always.

Tom Kyte
October 17, 2006 - 3:39 pm UTC

you cannot with native dynamic sql, it is a COMPILE TIME thing.


Your tables are statically defined and only statically accessible (there is no "access the attribute named in the variable...." type of access)

Parameterizing a view?

Ken, October 20, 2006 - 4:17 am UTC

This was very helpful to understanding ref cursors. Now i just need to implement them. I have 2 questions though.

1. Since this thread started out a while back would application contexts in the method described at the begining of the thread still be the preferred method in 10g?

2. Could this method be employed to paramerize a view essentially allowing predicate pushing into one that normally wouldn't allow it such as one with a group by or an analytical function?

create context x ...;

create view y as
select sum(col2), col3 from table1 where col1=sys_context(''x'',''col1_value'') group by col3;

create or replace procedure z
...
begin
dbms_session.set_context(''x'',''col1_value'',''6-oct-2005'');

for i in (select * from y, other_tables where ...)
....

end;
/

Thank you






Tom Kyte
October 20, 2006 - 7:07 am UTC

1) this applies to 10g as well as 9i and 8i

2) yup

</code> http://asktom.oracle.com/pls/ask/search?p_string=parameterized+view <code>



differing select

Chris, October 24, 2006 - 10:01 am UTC

Tom,
The info on application context's is great. However, how can I accomplish the same things where my select statements are different, but the resulting column list is the same. Let's say I currently have 5 static cursors declared that all fetch the same column list, but the tables may vary, the way the columns are defined in the select list may vary with decode's, etc. I want to open the appropriate cursor then go into one loop to fetch, not 5. Something like:

declare
cursor c1 is select ...
cursor c2 is select ...
cursor c3 is select ...
cursor c4 is select ...
cursor c5 is select ...
begin
if ...
open c1;
elsif ...
open c2;
elsif ...
open c3;
elsif ...
open c4;
elsif ...
open c5;
end if;
loop
fetch ? into col1, col2, col3, col4;
exit when ?%notfound;
... do something ...
end loop;
close ?

Looking for a way to open a ref cursor for a predefined static cursor, or set a ref cursor equal to another cursor so that I can use the ref cursor in the loop/fetch.

Tom Kyte
October 24, 2006 - 2:03 pm UTC

you would not use a predefined cursor, you would instead:

if ...
open c for select ... from t1, t2, ....
elsif
open c for select .... from t3, t4, ....




question about cursor variables across db links

Jim, October 27, 2006 - 11:26 am UTC

If this is off topic, let me know

My question is about the cursor rowtype variable in procedure:

in db1
create view v_local
as select * from mytab;

in db2

create procedure myproc
cursor c_mytabatdb1
is select * from v_local@db1;

mytab_row c_mytabatdb1%ROWTYPE;
begin

end;

If I compile all this and then recreate v_local with a reordering of the fields, is mytab_row already compipled to use the old field ordering, meaning that I need to recompile
myproc, or will it get the field order at run time?
I believe that the field ordering is done at compile time.
Or am I wrong?

Tom Kyte
October 27, 2006 - 6:21 pm UTC

remote dependencies are done via either

timestamp or signature.


both the timestamp of the remove view AND the signature of the remote view would have changed, causing the procedure to invalidate itself when it went to access it next.

dynamic statement in for loop

A reader, November 01, 2006 - 1:58 pm UTC


can i use dynamic statement in for loop like
or some other way to do it.
CREATE OR REPLACE PROCEDURE Sp_Temp(search IN VARCHAR2,
a OUT cursor_return,
b OUT cursor_return,
c cursor_return) IS

v_employee VARCHAR2(200);

BEGIN

FOR CUR IN ( 'SELECT EMPLOYEE_ID FROM employee WHERE'|| search)
LOOP
dbms_output.put_line('hello');
END LOOP;
END ;

Tom Kyte
November 01, 2006 - 6:21 pm UTC

nope, and a hope you really don't do that in real life - the ... where ' || search bit, that is horrible.

insecure (sql injection)
performance hog (no binds)
does not scale (no binds)


you have to use explicit cursors

open c for ...
loop
fetch c into ...
exit when c%notfound

EXAMPLE

A reader, November 01, 2006 - 6:14 pm UTC

here is an example i found from stanford.edu but when i define resukt set in another result set it does not allow me to do so

DECLARE
TYPE emp_cur_typ IS REF CURSOR;
emp_cur emp_cur_typ;
dept_name departments.department_name%TYPE;
emp_name employees.last_name%TYPE;
CURSOR c1 IS SELECT
department_name,
-- The 2nd item in the result set is another result set,
-- which is represented as a ref cursor and labelled "employees".
CURSOR
(
SELECT e.last_name FROM employees e
WHERE e.department_id = d.department_id
) employees
FROM departments d
WHERE department_name like 'A%';

BEGIN
OPEN c1;
LOOP
FETCH c1 INTO dept_name, emp_cur;
EXIT WHEN c1%NOTFOUND;
dbms_output.put_line('Department: ' || dept_name);
-- For each row in the result set, we can process the result
-- set from a subquery. We could pass the ref cursor to a procedure
-- instead of processing it here in the loop.
LOOP
FETCH emp_cur INTO emp_name;
EXIT WHEN emp_cur%NOTFOUND;
dbms_output.put_line(' Employee: ' || emp_name);
END LOOP;
END LOOP;
CLOSE c1;
END;
/


Tom Kyte
November 01, 2006 - 6:41 pm UTC

i seem to be missing some tables relevant to the example - so I cannot even get as far as you can!!

context and SELECT across a DBLink

David, November 02, 2006 - 12:49 pm UTC

The article in Oracle Magazine pointing me to this thread came at a most opportune time, as I am working on some ad hoc queries in which number of predicates in the WHERE clause will change.

My first test failed, in which I was selecting data from a table across a DBLink. I am able to select data from a table in my schema, but unable to get the dynamic SQL with a sys_context to work if I select from either a table across a DBlink, or even a view in that selects from a remote table.

permit@ORADEV> create or replace context permit_search using test_proc;

create or replace procedure test_proc as
type rc is ref cursor;
l_cursor rc;
l_query varchar2(512)
default 'select facility_id ' ||
'from snap.facilities@a_db_link ' ||
'where 1 = 1 ';

cursor l_template is
select facility_id
from snap.facilities@a_db_link;
l_rec l_template%rowtype;


begin
dbms_session.set_context('permit_search', 'facility_num', '0010005');
l_query := l_query || 'and facility_num = sys_context(''permit_search'', ''facility_num'') ';


p(l_query );

open l_cursor for l_query;
loop
fetch l_cursor into l_rec;
exit when l_cursor%notfound;
dbms_output.put_line('with sys_context: ' || l_rec.facility_id);
end loop;

close l_cursor;

l_query := 'select facility_id ' ||
'from snap.facilities@a_db_link ' ||
'where 1 = 1 ' ||
'and facility_num = ''0010005''';

p(l_query);
open l_cursor for l_query;
loop
fetch l_cursor into l_rec;
exit when l_cursor%notfound;
dbms_output.put_line('with hard-coded SQL: ' || l_rec.facility_id);
end loop;

close l_cursor;

end;
/

permit@ORADEV> exec test_proc
select arms_facility_id from arms_snap.arms_facilities@doppler where 1 = 1 and airsid =
sys_context('permit_search', 'airsid')

select arms_facility_id from arms_snap.arms_facilities@doppler where 1 = 1 and airsid = '0010005'

with hard-coded SQL: 1278

PL/SQL procedure successfully completed.

I'd really like to make this work, as I do not want to hit the database with queries that don't make use of bind variables.

Tom: Thank you for all your assistance over the years. I am planning on naming my first-born Bind Variable, in your honor. Unless my wife objects, of course. ;-)

Ciao,
David

Tom Kyte
November 02, 2006 - 7:25 pm UTC

if ( p_ename is NOT NULL ) then
l_query := l_query ||
' and ename like ''%''||:p_ename||''%''';
else
l_query := l_query ||
' and 1 = DECODE(:p_ename,NULL,1,1)';
end if;


(from above), else you'd have to call dbms-session@remote site... but that'd have be wrapped in a procedure @thatsite, and the context created over there....




facing a small issue with use of Context.

Vijay Sehgal, December 14, 2006 - 11:06 pm UTC

Dear Tom,
good day to you as always, we are facing a small issue when using context, if you can please help us out.

When a context is create from schema/user A and the schema is exported and imported in same database as user B the context is replaced and we start getting below errors

ORA-01031: insufficient privileges
ORA-06512: at "SYS.DBMS_SESSION".

In schema/user A,which is obvious.

To avoid this as of now,we have created different context from both schema A and B and the package using the context is also changed to refer proper context.

But in a situation where one database having multiple schemas and each schema being used by different team say development and testing, what is the best solution to handle this, rather than creating different context and changing the package as to avoid errors.

Your help in this regard is much appreciated.

Kind Regards,
Vijay Sehgal.

Tom Kyte
December 15, 2006 - 8:43 am UTC

a context is bound to a single package or standalone procedure/function.

ONLY that package/procedure/function can set it.

so if user A owned the package to set that context, only the package owned by A can set it.


Facing a problem with Ref Cursor

Pasha, December 18, 2006 - 5:29 am UTC

Hi Tom,

I was opening a Ref cursor and the select query for the cursor was using the " WITH " clause and i am getting this error message "PLS-00103:Encountered the symbol "WITH" when expecting one of the following:".

The WITH clause query is running perfectly in SQL window, but when i am using the same query in PL/SQL block to open the Ref Cursor above mentioned error is getting displayed and the procedure is not getting compiled.

--Following is the code used in the procedure

OPEN id_info_cur FOR (WITH main_query AS
(
SELECT a.product_name,
a.product_code_ato,
a.destination,
a.model_id,
fi.display_name,
dv.val,
dv.priority
FROM itpcs_tran_grt_mdl_mast a,
itpcs_grt_mdl_dmi_info_vw dv,
itpcs_list_grt_func_items fi
WHERE DECODE (prod_name,
NULL, a.product_code_ato,
a.product_name) LIKE
DECODE (prod_name,
NULL, prod_code,
prod_name)
|| '%'
AND dv.key_info = a.model_id(+)
AND dv.info = fi.function_item
AND dv.priority = fi.field_type),
dt_data AS
(SELECT DISTINCT product_name,
product_code_ato,
destination
FROM main_query)
SELECT product_name,
product_code_ato,
destination,
display_name,
val
FROM main_query
UNION ALL
SELECT product_name,
product_code_ato,
destination,
'ESID - M',
NULL
FROM dt_data
WHERE NOT EXISTS (
SELECT 1
FROM main_query a
WHERE a.display_name LIKE 'ESID%'
AND a.product_code_ato =
dt_data.product_code_ato
AND a.destination =
dt_data.destination)

Please advice.

Thanks & Regards,
Pasha.

Tom Kyte
December 18, 2006 - 8:31 am UTC

ops$tkyte%ORA10GR2> declare
  2          c sys_refcursor;
  3  begin
  4          open c
  5          for
  6          with data
  7          as
  8          (select * from dual)
  9          select * from data;
 10  end;
 11  /

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> declare
  2          c sys_refcursor;
  3  begin
  4          open c
  5          for
  6          (with data
  7          as
  8          (select * from dual)
  9          select * from data
 10          );
 11  end;
 12  /
        (with data
         *
ERROR at line 6:
ORA-06550: line 6, column 3:
PLS-00103: Encountered the symbol "WITH" when expecting one of the following:
( - + case mod new not null others <an identifier>
<a double-quoted delimited-identifier> <a bind variable> avg
count current exists max min prior sql stddev sum variance
execute forall merge time timestamp interval date
<a string literal with character set specification>
<a number> <a single-quoted SQL string> pipe
<an alternatively-quoted string literal with character set specification>
<an alternativel


you have () where they should not be. 

sys_context & sys refcursors passed back to the clients

A Reader, December 22, 2006 - 8:16 am UTC

Hi Tom

the 1st post in this thread which shows how to use sys_context to build a query with varying WHERE clause still using bind variables is a great example and very useful.

Will this approach work for procedures which OPEN and pass a sys refcursor back to the client ? My confusion is because the client that processes the refcursor (Fethes data) is a separate program in Java/.NET etc and i am not sure if the context information is available to it.

If it wont work in those situations - can you suggest some alternate mechanism to use a dynamic WHERE clasue which still uses Bind Variables in those situations.


Thanks in advance

Tom Kyte
December 24, 2006 - 8:44 am UTC

this approach is DESIGNED for the case where a procedure opens the ref cursor and passes it back, yes, the sys_context information is evaluated at "OPEN" time.


sys_context & sys refcursors passed back to the clients

A Reader, December 24, 2006 - 7:58 pm UTC

Hi Tom,

Thanks for your response - one further clarification - your earlier post said that the syscontext values are set/retrieved in the context of a package/procedure/function.

If a package/procedure/function is called by the front-end application to return the refcursor - isn't there a possiblility of these values getting 'mixed' up amongst multiple calls to the same procedure

for eaxmaple :

1) front-end-instance-1 calls proc1 (instance1)
2) proc1 (instance1) stores 'stuff' in syscontext
3) front-end-instance-2 calls proc1 (instance2)
4) proc1 (instance2) stores 'stuff' in syscontext
5) proc1 (instance1) Opens the cursor [oops with values that were stored by proc1 (instance2)]

Is this a concern ? If so how best can it be addressed ?

Thanks in advance.
Tom Kyte
December 25, 2006 - 7:09 am UTC

each session has their own "session" - instance 1 and instance 2 would not "share" context values.

Accessing Data over DB Link, referring a REFCURSOR

Anenthan, January 01, 2007 - 7:48 am UTC

Hi Tom,

This is the first time I am writing to you, we have two databases, and when I call a stored procedure over the DBLink which has a REF CURSOR as output parameter and after executing the procedure over the DBLINK I get the following error when i try to print the REFCURSOR. It executes without any problem and prints the data on the DB where there physical schema is.

SQL> EXECUTE MIRN.GET_FORMULA(:M_RESULT);

PL/SQL procedure successfully completed.

SQL> print m_result
ERROR:
ORA-24338: statement handle not executed

I am using synonyms to access the procedure on the other DB over the DB Link. We are getting the same error at application layer also.

Tom Kyte
January 01, 2007 - 9:17 am UTC

you have a bug in your code, you have a "when others then null" or equivalent I'll guess.

Why do I say that?

because ref cursors cannot be returned over the database link, you are getting an error to that effect, and you are ignoring it.

You have a serious bug in your developed code. Look to your exception handlers and whenever you see yourself catching an exception and not re-raising it (eg: you handle it) ask yourself if you are doing something "smart"

in this case, the answer will be "no"

Accessing Data over DB Link, referring a REFCURSOR

Anenthan, January 02, 2007 - 3:31 am UTC

Hi Tom,

Not that we are not handling the error, we don't wont the error to come in the first place, just wanted to confirm whether we can use REFCURSORS over DB Link. We found a workaround thanks for the very prompt reply.

Anenthan

Avoiding re-parsing and context cleanup

SG, February 06, 2007 - 12:27 pm UTC

Tom,

First of all - great tip !

If I understood correctly, the purpose of using context in this specific example is to avoid building dynamic query with actual values, and, I assume, to avoid query re-parsing during runtime. Does not Oracle treat two queries with differences only in constants values as same in terms of parsing and execution plan ? i.e. would it re-parse if we just used values instead of sys_context ? I think there is a database parameter for this behavior.

Also, in the applications with shared sessions / connection pooling, I would explicitly clean up context values if corresponding parameters are null. This is just so that other application components that may use the same context do not get incorrect values. Although the code as given would work just fine in this regard.

Thanks,
SG.

Tom Kyte
February 06, 2007 - 12:54 pm UTC

select * from emp where empno = 1;
select * from emp where empno = 2;

those are two very different queries, they will not be shared. In fact:

SELECT * FROM DUAL;
select * from dual;

those are two very different queries, they will not be shared.


the database parameter you are talking about is the dreaded cursor_sharing parameter - set to force or similar, it will cause literals to be ripped out and bound. I never suggest using it - it indicates a serious bug in the developed code that needs, must be, fixed.

sys_context bind variables and parsing

los, February 06, 2007 - 7:52 pm UTC

This may appear like a dumb question, but can you explain where it is suitable to use sys_context and where to use a simple bind varibale (:variable) and the difference in parsing?

Why does sys_context get parsed differently then a strong variable when as I see it they just as free to hold anything?
Tom Kyte
February 07, 2007 - 1:02 pm UTC

you use sys_context when you cannot use :variable.


for example, in the above, using a :bind_variable would be difficult if not impossible - hence - sys_context to the rescue.

sys_context was invented for fine grained access control - where you have the need to "bind" a query, but since you are not coding the query itself (you are adding to the where clause), we needed another way. So, sys_context to the rescue.

What do you mean by "get parsed differently"?

SET_CONTEXT.VALUE LIMIT

Charlie, February 16, 2007 - 2:26 pm UTC

Hello Tom,

In 10g 10.2.0.2, the max chars allowed in set_context seem still be 256, though the online doc states 4K below. Is this a bug?

------------------------
Syntax

DBMS_SESSION.SET_CONTEXT (
namespace VARCHAR2,
attribute VARCHAR2,
value VARCHAR2,
username VARCHAR2,
client_id VARCHAR2 );

Parameters

Table 96-14 SET_CONTEXT Procedure Parameters
Parameter Description
namespace The namespace of the application context to be set, limited to 30 bytes.
attribute The attribute of the application context to be set, limited to 30 bytes.
value The value of the application context to be set, limited to 4 kilobytes. <====
username The database username attribute of the application context.

Default: NULL
client_id The application-specific client_id attribute of the application context (64-byte maximum).

Default: NULL
---------------------

Here is my test,
create or replace procedure test_value
is
    v_value varchar2(4000);
begin
    select lpad('x', 1000, 'x') 
    into v_value
    from dual;

    dbms_session.set_context('my_ctx', 'name', v_value);   
        
    dbms_output.put_line('len=' || length(sys_context('my_ctx', 'name'))); 
end;
/

create or replace context my_ctx using test_value;

exec test_value;


thanks,
Tom Kyte
February 18, 2007 - 8:43 am UTC

sys_context has a default 3rd parameter that controls the returned length for backwards compatibility:

ops$tkyte%ORA10GR2> create or replace procedure test_value
  2  is
  3          l_len   number;
  4  begin
  5      dbms_session.set_context('my_ctx', 'name', rpad('x',1000,'x') );
  6      dbms_output.put_line('len=' || length(sys_context('my_ctx', 'name',4000)));
  7  end;
  8  /

Procedure created.

ops$tkyte%ORA10GR2> create or replace context my_ctx using test_value;

Context created.

ops$tkyte%ORA10GR2> exec test_value;
len=1000

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> select length(sys_context('my_ctx','name')),
  2         length(sys_context('my_ctx','name',4000))
  3    from dual;

LENGTH(SYS_CONTEXT('MY_CTX','NAME')) LENGTH(SYS_CONTEXT('MY_CTX','NAME',4000))
------------------------------------ -----------------------------------------
                                 256                                      1000

ops$tkyte%ORA10GR2>



I can't use this method with function in_list

Francisco Caserio, February 27, 2007 - 3:39 pm UTC

Tom

I got a huge improvement on my queries using the method you described.
I just couldn't use it with function in_list:

I'm using set_context as described:
dbms_session.set_context('PESQ_CTX', 'str_download', str_download);

if I the following syntax the procedure compiles but when I run the proc I get an error (ORA-00918: coluna definida de maneira ambÝgua):
dig_where := dig_where || 'table.id_area IN (SELECT * FROM THE (SELECT CAST(in_list(sys_context(''PESQ_CTX'', ''str_download'')) AS mytableType) FROM dual)) AND ';

I only can run the query if I use on this way:
dig_where := dig_where || 'table.id_area IN (SELECT * FROM THE (SELECT CAST(in_list(' || str_download || ') AS mytableType) FROM dual)) AND ';

What is the difference between the 2 versions? Do I have much performance improvement using set_context?

This is the complete code:

CREATE OR REPLACE CONTEXT PESQ_CTX USING pr_get_teste;
CREATE OR REPLACE PROCEDURE pr_get_teste(
keyword varchar,
str_download varchar,
regxpg int,
pg int,
p_cur_dig OUT SYS_REFCURSOR)
AS
dig_where varchar2(1000);
dig_query varchar2(4000) default 'SELECT *
FROM (SELECT a.*, rownum rnum
FROM (SELECT
table.id,
table.name
FROM table
INNER JOIN table2...
INNER JOIN table3...
WHERE
[WHERE]
1 = 1
GROUP BY
table.id,
table.name
ORDER BY
table.id DESC) a
WHERE rownum <= [REGXPG] * [PG])
WHERE rnum > [REGXPG] * ([PG]-1)';
BEGIN
-- keyword
IF keyword IS NOT NULL THEN
dbms_session.set_context('PESQ_CTX', 'detail', str_search);
dig_where := dig_where || 'CONTAINS(table.detail, sys_context(''PESQ_CTX'', ''detail'')) > 0 AND ';
END IF;
-- download rights
IF str_download IS NOT NULL THEN
dbms_session.set_context('PESQ_CTX', 'str_download', str_download);
dig_where := dig_where || 'table.id_area IN (SELECT * FROM THE (SELECT CAST(in_list(sys_context(''PESQ_CTX'', ''str_download'')) AS mytableType) FROM dual)) AND ';
--dig_where := dig_where || 'table.id_area IN (SELECT * FROM THE (SELECT CAST(in_list(' || str_download || ') AS mytableType) FROM dual)) AND ';
END IF;
-- query
dbms_session.set_context('PESQ_CTX', 'regxpg', regxpg);
dbms_session.set_context('PESQ_CTX', 'pg', pg);
dig_query := replace(dig_query, '[REGXPG]', 'sys_context(''PESQ_CTX'', ''regxpg'')');
dig_query := replace(dig_query, '[PG]', 'sys_context(''PESQ_CTX'', ''pg'')');
dig_query := replace(dig_query, '[WHERE]', dig_where);
--var_debug := var_debug || dig_query;
OPEN p_cur_dig FOR replace(dig_query, '[WHERE]', dig_where);
END;
/


Tom Kyte
February 27, 2007 - 3:42 pm UTC

not really sure what your goal here is - can you state the "problem"


i don't know what you mean

and please - for the love of whatever - BIND BIND BIND

RE: I can't use this method with function in_list

Francisco Caserio, February 27, 2007 - 5:50 pm UTC

OK, I'll try to explain again

My procedure receives a comma separated list os numbers that I compare using:

field IN (SELECT * FROM THE (SELECT CAST(in_list(str_download)) AS mytableType) FROM dual))

I transformed the query proc using set_context:

dbms_session.set_context('PESQ_CTX', 'str_download', str_download); 

qry_where := qry_where || 'table.id_area IN (SELECT * FROM THE (SELECT CAST(in_list(sys_context(''PESQ_CTX'', ''str_download'')) AS mytableType) FROM dual)) AND ';


I can compile the proc, but once I execute I receive an error (ORA-00918).

The only way I could do it is without context:

qry_where := qry_where || 'table.id_area IN (SELECT * FROM THE (SELECT CAST(in_list(' || str_download || ') AS mytableType) FROM dual)) AND ';


My questions is:
Do I have much performance improvement using set_context?
What am I doing wrong I can't use set_context on this situation.

That's it. Anyway, thanks for your attention.
Tom Kyte
February 28, 2007 - 2:50 pm UTC

ops$tkyte%ORA10GR2> create or replace type str2tblType as table of varchar2(30)
  2  /

Type created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> create or replace function str2tbl( p_str in varchar2, p_delim in varchar2 default ',' ) return str2tblType
  2  PIPELINED
  3  as
  4      l_str      long default p_str || p_delim;
  5      l_n        number;
  6  begin
  7      loop
  8          l_n := instr( l_str, p_delim );
  9          exit when (nvl(l_n,0) = 0);
 10          pipe row( ltrim(rtrim(substr(l_str,1,l_n-1))) );
 11          l_str := substr( l_str, l_n+1 );
 12      end loop;
 13      return;
 14  end;
 15  /

Function created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> create or replace context my_ctx using p
  2  /

Context created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> create or replace procedure p( p_str in varchar2, p_cursor in out sys_refcursor )
  2  as
  3  begin
  4          dbms_session.set_context( 'my_ctx', 'str', p_str );
  5          open p_cursor
  6          for '
  7          select *
  8            from scott.emp
  9           where ename in (select * from TABLE( cast(str2tbl(sys_context(''my_ctx'',''str'')) as str2tblType)) )';
 10  end;
 11  /

Procedure created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> variable x refcursor
ops$tkyte%ORA10GR2> exec p( 'KING,SMITH,SCOTT', :x )

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> print x

     EMPNO ENAME      JOB              MGR HIREDATE         SAL       COMM     DEPTNO
---------- ---------- --------- ---------- --------- ---------- ---------- ----------
      7839 KING       PRESIDENT            17-NOV-81       5000                    10
      7369 SMITH      CLERK           7902 17-DEC-80        800                    20
      7788 SCOTT      ANALYST         7566 19-APR-87       3000                    20


sys_context Approcah

ram, May 04, 2007 - 9:10 am UTC

Hi tom,

I had some hot discussions with some of the developers working with me on the usage of sys_context as an easy method when there are varying number of bind variables to be fixed and this will be cumbersome while using the standard approach (USING CLAUSE).

How ever the developement Lead was stubborn and was pointing some issues which were irrelevant in our system.
The Lead was making the following points.

"Sys context cannot be used with parallel queries (as it returns session attributes) or Real time application cluster( (if parallel queries are introduced in the future the application may not work as desired)".

"SYS_CONTEXT is a VPD feature , its an overburden to use this as a substitute for Bind Variables"

"It comes with few bugs which are fixed in later versions. An excel sheetattachment containing few bugs associated with the usage of sys_context that we gathered from oracle metalink"

I had to tell them that we are no way using the parallel qury and nor in the near future we are going to implement the same, it not "REAL TIME APPLICATION CLUSTER" ..Its Real Application Cluster.I have failed miserably over here ...The code was finally written with a complex logic and is ready for deployment as well....

But anyway thanks a ton for the excellent inputs on this and making us understand about this.

Your Thoughts are Beyond the Obvious ...


Tom Kyte
May 04, 2007 - 1:14 pm UTC

... "SYS_CONTEXT is a VPD feature , its an overburden to use this as a substitute for Bind Variables" ...

it was added to provide for binding with VPD - it's purpose in LIFE is to be a bind.

there are bugs with select, insert, update, delete and merge - some are not fixed until later releases. Now what?

parallel...

big_table%ORA10GR2> create or replace context my_ctx using my_proc
  2  /

Context created.

big_table%ORA10GR2> create or replace procedure my_proc
  2  as
  3  begin
  4          dbms_session.set_context( 'my_ctx', 'x', '1' );
  5  end;
  6  /

Procedure created.

big_table%ORA10GR2> exec my_proc

PL/SQL procedure successfully completed.

big_table%ORA10GR2>
big_table%ORA10GR2> @mystat "queries parallelized"
big_table%ORA10GR2> set echo off

NAME                        VALUE
---------------------- ----------
queries parallelized            0

big_table%ORA10GR2> select /*+ full(big_table) parallel(big_table,8) */ count(*)
  2  from big_table where sys_context( 'my_ctx', 'x' ) = '1';

  COUNT(*)
----------
   1000000

big_table%ORA10GR2> @mystat "queries parallelized"
big_table%ORA10GR2> set echo off

NAME                        VALUE
---------------------- ----------
queries parallelized            1

Excellent

RAM, May 04, 2007 - 1:39 pm UTC

Tom ,

That was simply superb !!

Cursor Expressions

Hariharan Ragunathan, May 07, 2007 - 6:44 am UTC

Hi Tom,
I read about cursor expressions in oracle documentation. Using that I wrote a query similar to the one following,

select t1.a, cursor(select t2.b,t2.c from t2
where t2.a= t1.a)
from t1;
When I use this in PL/SQL Procedure to declare a cursor, the following error occurs.

PLS-00989: Cursor Variable in record, object, or collection is not supported by this release.

I am using Oracle version 9.2.0.7. Will this work in this version? Please tell me where we can apply this cursor expression functionality. Kindly help me in this

Permutations and Combinations

Bhushan, May 10, 2007 - 6:51 am UTC

Hi Tom,
Please let me know what would be your approach in the following Scenario.
We have the following quantities in containers (sorted ascending by date).
5,1,1,2,2,7,7.Whenever a quantity is requested the oldest one should be shipped out first.The quantities in a container cannot be split.
So if 7 is requested then 5,1,1 is shipped out.
if 9 is requested 5,1,1,2 is shipped out.
Scenarior number 2:
Available Quantities 5,1,3,10,5
Requested Quantity 10 , so 5,5 (first and last 5) would be shipped out since the priority is to get rid of the oldest container.
I did manage to write a code but it contains lots of loops and i am sure it is not the best way to do.

Hope the above scenarios make my question clear.i will be eagerly waiting for your response.



Cheers!!!
Bhushan

PS: In reality the quantities can vary from 40 to 50 different quantities. Also i am not allowed to create any view or temp tables in the DB. Any thoughts....


Tom Kyte
May 11, 2007 - 10:43 am UTC

no create table
no inserts
no example
no look

Permutations and Combinations

Bhushan, May 10, 2007 - 1:40 pm UTC

the DB version for the above mentioned question is 8.1.7.4.0

Permutations and Combinations

Bhushan, May 18, 2007 - 2:38 am UTC

Here you go Mr. Tom
CREATE TABLE bhu_test (date_time DATE,qty NUMBER(10,2))
INSERT INTO bhu_test VALUES (SYSDATE-2,4)
INSERT INTO bhu_test VALUES (SYSDATE,2)
INSERT INTO bhu_test VALUES (SYSDATE-1,5)
INSERT INTO bhu_test VALUES (SYSDATE-1,6)
INSERT INTO bhu_test VALUES (SYSDATE-2,3)
Now,
SELECT * FROM bhu_test ORDER BY date_time
which will give us 3,4,5,6,2
If the required quantity is 7 then select 3 and 4
If the required Quantity is 8 then select 3 and 5
If the required quantity is 9 then select 3 and 6

Now here we have considered a summation of only digits to gether it may also happen that to achieve the required quantity we may have to add more than 2 digits.

For Eg.
If the required quantity is 12 then select 3,4 and 5

Bottom LIne the Oldest one should be given a preference and taken out.

WHat approach would you use/suggest.

Cheers!!!
Bhushan

Using set_context in ApEx

Earl Lewis, May 21, 2007 - 5:05 pm UTC

Tom,

I've got quite a few situations where my Application Express (ApEx) pages can take variable input parameters to dynamically generate the query predicates to give users flexibility in their querying my apps. The ApEx developers have been very kind by including a report source type of 'PL/SQL function returning SQL query' that satisfies my technical requirement. I would assume (based on this thread) that this goes completely counter to what you would consider good PL/SQL application programming.

I've been trying to adapt your technique described here to one of my ApEx applications, but as far as I know there is no facility in ApEx that can take a cursor (or ref cursor) as the source of an ApEx report. Do you know if it's possible to adapt this technique to ApEx? Thank you for your time and consideration.

Earl
Tom Kyte
May 22, 2007 - 9:23 am UTC

no, not really - apex "binds", if the developers use the V() function or they use :item_name - it is well bound.

if they return a query with literals, then we have a problem.

I demonstrated a ref cursor, but the SAME concept works with dbms_sql (used by apex). basically you build a string, and they open it.

However, if you just reference apex items in there - it'll bind them automagically for you (I wrote that bit of code way back when - parse a sql statement for the :identifier strings and bind them in using calls to V() )

ApEx binds

Earl Lewis, May 22, 2007 - 2:00 pm UTC

Tom,

Thanks for that bit of insight on the inner workings of ApEx, and your part in it.

My approach so far has been to write a function (in a package) that returns the SQL string. The function takes care of creating the string and returning a varchar2 with/without the optional where clause predicates. In my ApEx apps, for the report region source I put a call like this:
begin
l_sql := my_pkg.my_sql_query(:P_ITEM1, :P_ITEM2);
return l_sql;
end;


Is this OK? It works fine, from an end-result point of view, but I'm really trying to follow your advice on using binds and getting parse time down to a minimum.

Thanks again for your time and advice.

Earl


Tom Kyte
May 22, 2007 - 7:07 pm UTC

depends - PROBABLY NOT though.


you are sending the values of :p_item1 and :p_item2 to the routine, sort of like:

l_sql := my_pkg.my_sql_query( 'X', 'Y' );

so the query you return will look like:

select * from t where a = 'X' and b = 'Y'


I would send instead the NAMES

l_sql := my_pkg.my_sql_query( ':P_ITEM1', ':P_ITEM2');

so you return a query like:

select * from t where a = :p_item1 and b = :p_item2;


that'll "bind"

Permutation and Combinations

Bhushan, May 22, 2007 - 2:03 pm UTC

Hey,
Was my Question ignored or was i not clear again :-/

Rgds,
Bhushan
Tom Kyte
May 22, 2007 - 7:09 pm UTC

given this input:

....
Here you go Mr. Tom
CREATE TABLE bhu_test (date_time DATE,qty NUMBER(10,2))
INSERT INTO bhu_test VALUES (SYSDATE-2,4)
INSERT INTO bhu_test VALUES (SYSDATE,2)
INSERT INTO bhu_test VALUES (SYSDATE-1,5)
INSERT INTO bhu_test VALUES (SYSDATE-1,6)
INSERT INTO bhu_test VALUES (SYSDATE-2,3)
Now,
SELECT * FROM bhu_test ORDER BY date_time
which will give us 3,4,5,6,2
If the required quantity is 7 then select 3 and 4
If the required Quantity is 8 then select 3 and 5
If the required quantity is 9 then select 3 and 6

Now here we have considered a summation of only digits to gether it may also happen that to achieve the required quantity we may have to add more than 2 digits.

For Eg.
If the required quantity is 12 then select 3,4 and 5

Bottom LIne the Oldest one should be given a preference and taken out.

WHat approach would you use/suggest.
.....


I have no output for you. I don't really page up down and all around to reconstruct things - I just saw that and said "hmm, no idea what is meant, next"

ApEx binds

Earl Lewis, May 23, 2007 - 1:54 pm UTC

You said...

depends - PROBABLY NOT though. you are sending the values of :p_item1 and :p_item2 to the routine, sort of like:

l_sql := my_pkg.my_sql_query( 'X', 'Y' );

so the query you return will look like:

select * from t where a = 'X' and b = 'Y'


I would send instead the NAMES

l_sql := my_pkg.my_sql_query( ':P_ITEM1', ':P_ITEM2');

so you return a query like:

select * from t where a = :p_item1 and b = :p_item2;

that'll "bind"


This is great! It works like a charm. My DBA is going to be very happy with this improvement. Thanks again.

Earl

Was this concept intuitive for you?

Rahul, May 24, 2007 - 2:29 pm UTC

Tom,

I am just trying to understand how you have gone about and apply sys_context (a VPD concept) to the dynamic query execution? Was it intuitive for you? I am curious to know how it was intuitive if it was.

Thank you,
Rahul
Tom Kyte
May 26, 2007 - 11:36 am UTC

it was extremely intuitive.

you have a function that returns a value you can set.

Cursor taking more time

Datta, June 09, 2007 - 11:42 am UTC

Hi Tom,

If i am running a query from SQL Plus it is giving me output in a seconds but same query when putting into the cursor it is taking so long...

Please guide me on the same issue, why it is happening like this.

Thanks in Adv.

Datta


Tom Kyte
June 09, 2007 - 1:29 pm UTC

define "putting into the cursor" since - well - sqlplus only uses cursors.

here is what I think - you have a query that returns rows IMMEDIATELY, but takes a really long time to get to the last row.

When you run it in sqlplus as a straight select - and start seeing data right off - you say "my, how incredibly fast". then you control c or something (or just never really think about how long it takes to get to the last row)

When you run it in plsql (which I presume is what you mean by "putting into cursor") you have to wait for the last row to be processed before seeing any output.

You think "man, that takes long", but they take the same.


use SQL_TRACE, see what you see in the tkprof report.

And - very important - please make sure you are comparing the same query, eg:

select * from t where x= 5;

is NOT the same as:

select * from t where x= ?;


cursor efficiency

Piotr, June 12, 2007 - 3:06 am UTC

Hi,

I have to take some top 5 records from table and i wonder which solution is more efficient?

1.
cursor c is select col1,col2,col3 from table order by 3;

and now take 5 rows in typical loop like: open cursor, loop, fetch, end loop;

2.
cursor c is select * from (select col1,col2,col3 from table order by 3) and rownum <6;

And now take all rows from cursor

Is there any difference between that two ways??


Tom Kyte
June 12, 2007 - 10:06 am UTC

absolutely there is.

Oracle has a special top-n query optimization
Oracle recognizes the second query should be 'first rows' style optimized



read:
https://www.oracle.com/technetwork/issue-archive/2006/06-sep/o56asktom-086197.html
and
https://asktom.oracle.com/Misc/oramag/on-top-n-and-pagination-queries.html

Most interesting

James McNaughton, June 15, 2007 - 10:24 am UTC

Yet another very useful tool I wasn't aware of, and there was a situation I found myself in last year where I could have used it.

I did the following instead:

1. Assembled the dynamic SQL string using concatenation.

2. (VERY IMPORTANT) Before I executed the dynamic SQL, I used EXECUTE IMMEDIATE to run the following statement:

ALTER SESSION SET CURSOR_SHARING = FORCE;

3. I ran the dynamic SQL statement.

4. I then used EXECUTE IMMEDIATE to run:

ALTER SESSION SET CURSOR_SHARING = EXACT;

NOTE: CURSOR_SHARING was set to EXACT at SYSTEM level.

Tom, what are your views regarding this approach? Had I been aware of the context option, I would probably have gone down that road instead.
Tom Kyte
June 15, 2007 - 12:02 pm UTC

two words:

SQL INJECTION

google it.

I'd rather not use cursor sharing force for this, no.

PL/SQL misbehaviour

Apurva, June 20, 2007 - 6:39 am UTC

Tom,

I am trying to write a PL/SQL code which'd give me the records count for all the tables in the schema.

This piece of code is not working:

SET feedback OFF;
SET serveroutput ON;
DECLARE
v_dmth_id RECORD_COUNT_LOG.dmth_id%TYPE;
v_record_count RECORD_COUNT_LOG.record_count%TYPE;
CURSOR c_table_names IS SELECT object_name FROM USER_OBJECTS WHERE object_type = 'TABLE' AND object_name = 'DIM_GEO';
v_table_name c_table_names%ROWTYPE;
v_tbl VARCHAR(30);
BEGIN
 OPEN c_table_names;
 LOOP
   FETCH c_table_names INTO v_table_name.object_name;
   EXIT WHEN c_table_names%NOTFOUND;                               dbms_output.put_line('TableName:'||v_table_name.object_name);
   v_tbl := v_table_name.object_name;
   dbms_output.put_line('TableName:'||v_tbl);
   
<b>   SELECT COUNT(*) AS rc INTO v_record_count  FROM v_tbl;</b>

   INSERT INTO RECORD_COUNT_LOG VALUES (v_table_name.object_name, TO_DATE('1/1/2007','mm/dd/yyyy'), v_record_count);
   
  END LOOP;
  CLOSE c_table_names;
EXCEPTION
   WHEN OTHERS THEN
      DBMS_OUTPUT.PUT_LINE
           ('Error Encountered');

END;
/



The problem is with line:
SELECT COUNT(*) AS rc INTO v_record_count FROM v_tbl;

If I just alter the above line to:

SELECT COUNT(*) AS rc INTO v_record_count FROM DIM_GEO;

the code works...

What's puzzling me is: why am I not able to Select from v_tbl ? although the dbms_output is able to reference it

Thanks a lot~

Sincere Regards
Tom Kyte
June 20, 2007 - 10:43 am UTC

you cannot bind a tablename, you cannot in fact bind an identifier...

http://asktom.oracle.com/pls/ask/search?p_string=%22bind+an+identifier%22


execute immediate 'select count(*) from ' || v_tbl into l_cnt;

Thanks Tom!

A reader, June 20, 2007 - 12:30 pm UTC


Column Name in Ref cursor

Raghav, July 05, 2007 - 10:42 am UTC

Hi Tom

Is there any way to identify the column name in a ref cursor?

Problem: There is a table having some or all columns data of 4 different tables. The columns may be dynamically change but they are available in the base tables.

I am trying to fetch the data of dynamic columns related to one base table from that big table and insert them into the base table.

For the purpose I am using ref cursors. To get the values and pass it on to those columns I need to know the column names of the cursor so that I can manipulate the data of that column.


Thanks in advance
Raghav
Tom Kyte
July 05, 2007 - 1:18 pm UTC

you can certainly get the column name - just describe the query (well, except in plsql prior to 11g... before then, in plsql - no).

but that won't tell you the table

column name in a ref cursor

Raghav, July 06, 2007 - 2:40 am UTC

Hi Tom

Thanks for your quick reply. Can you please give me an example / syntax to identify the column name in a reference cursor. I am trying to get this in a pl/sql block (using toad). Oracle version is 10.2.

Is there any other method we can use for the earlier said operation.

Thanks in advance
Raghav
Tom Kyte
July 06, 2007 - 12:40 pm UTC

I think I said - plsql cannot.

(well, except in plsql prior to 11g... before then, in plsql - no).

How is this different from using the 'USING' clause?

Rahul, July 26, 2007 - 4:20 pm UTC

Tom,

Thank you for all your help. I have a question.

Let's say I have to return a 'sys_refcursor' to the front end application. Now, if I build my query dynamically using ':x' variables and bind them using 'USING' clause....

Then, my dynamic query is still using bind variables, right? Or am I missing something for this particular case?
Tom Kyte
July 27, 2007 - 9:14 am UTC

you are using binds, yes.

Could it be because of

Rahul, July 26, 2007 - 4:45 pm UTC

Could it be because I have to write different 'open cursor USING' loops for different combinations?
Tom Kyte
July 27, 2007 - 9:19 am UTC

could what be?

What I meant is...

Rahul, July 27, 2007 - 12:52 pm UTC

What I meant is. Let's say I have one parameter that is not null. Then, my NDS statement is written this way.
if p_first_parameter is not null 
   and p_second_parameter is null
then
  open cursor for l_string USING p_first_parameter;
elsif p_first_parameter is null and
      p_second_parameter is not null 
then
  open cursor for l_string USING p_second_parameter;
elsif p_first_parameter is not null and
      p_second_parameter is not null
then
  open cursor for l_string USING p_first_parameter, p_second_parameter;
elsif p_first_parameter is null and
      p_second_parameter is null
then
  open cursor for l_string;
end if;

So, two parameters, I HAVE to write my NDS this way, else, it won't take all the permutations.

BUT, if I follow your way of sys_context, I guess I don't have to all these permutations of the NDS statements.

Am I right or not? I guess that is why using sys_context is always better than using NDS with 'USING' thing.

Thank you,
Rahul.


Tom Kyte
July 27, 2007 - 3:28 pm UTC

nothing is always better.

everything is just a technique, a way, an approach, an option.


your example doesn't make sense, since l_string is never changing - twice you open it using a single bind, once with two and once with none - you obviously need three different strings. but you only have one.

Let's say I have three different l_strings.

Rahul, July 27, 2007 - 5:01 pm UTC

Tom,

That is the deal. My l_string is different in all the four cases accordingly. I am using the same logic to build my l_string too. So, in different situations, my l_string is different.


Tom Kyte
July 27, 2007 - 8:26 pm UTC

well, I still say your example is bad then - it would be using static sql, it would be

if ( x is not null and y is null )
then
open c for select .... where column = x;
else...

you would NOT be using dynamic sql here in that case. you would be using static and static has definite advantages.

so, I refuse to say "better" - or "worse" - just different.


If you have lots of inputs - then using sys_context with native dynamic sql makes sense.

Your example, static might be better.

Wrapping Context access into a package

Fred, July 31, 2007 - 4:39 pm UTC

Hi Tom,

Incredibly valuable information here!!! Thank you!

I want to "wrap" the access to my context in a package to make it a little simpler to use. Here is an example

create or replace
PACKAGE CTX AS
PROCEDURE SetVal(
VarName_In IN VARCHAR2,
VarValue_In IN VARCHAR2
);

FUNCTION GetVal(
VarName_In IN VARCHAR2
) RETURN VARCHAR2;
END CTX;

PACKAGE BODY CTX AS
PROCEDURE SetVal(
VarName_In IN VARCHAR2,
VarValue_In IN VARCHAR2
) AS
BEGIN
DBMS_SESSION.SET_CONTEXT('MY_CTX', VarName_In, VarValue_In);
END SetVal;

FUNCTION GetVal(
VarName_In IN VARCHAR2
) RETURN VARCHAR2 AS
BEGIN
RETURN SYS_CONTEXT('MY_CTX', VarName_In);
END GetVal;
END CTX;

CREATE CONTEXT CTX USING SchemaName.CTX

When using these functions in a dynamic statement such as

BEGIN
CTX.SetVal('SomeVar', 'A new Value');
EXECUTE IMMEDIATE 'UPDATE T
SET Field1=CTX.GetVal(''SomeVar'')';
END;

1. Is this still using binding or must I use SYS_CONTEXT() directly?
2. Would there be a performance degradation using this approach?

Thank you for your time.
Tom Kyte
August 02, 2007 - 10:40 am UTC

you should just call sys_context(), there is a large overhead to invoking that plsql routine over and over again.

I suggest erasing the getval routine entirely.

fetching the 4th row directly

chakri, August 03, 2007 - 2:41 am UTC

very useful. k tom i have a question how to fetch the 4th row directly instead of starting from the frist row. see my table is having 30 records i have written a cursor that will fetches 10 rows based on the condition . k . now i want the 4 th row direclty. i tried with DBMS_SQL.fetch_rows and its giving one record when i again ran the block its giving one record only but not the same record that came in the first trail. could you plz help me..
Tom Kyte
August 05, 2007 - 1:24 pm UTC

select * 
  from (select a.*, rownum rnum
          from (YOUR_QUERY_HERE)
         where rownum <= 4)
 where rnum = 4;


or

select * 
  from (select ...., row_number() over (your order by goes here) rn
          from ....
       )
where rn = 4;



k...

plz - german postal codes? that is confusing ....

Get the question right.

Rahul, August 03, 2007 - 3:06 am UTC

Chakri,

Tom hates IM speak ( u for 'you' etc). I suggest you get your question right in understandable english.

sorry for that

chakri, August 06, 2007 - 12:01 am UTC

sorry for that. I thought that might be understandable . Anyways thanks for the answer . Thanks

Thanks,
chakri
Tom Kyte
August 06, 2007 - 11:40 am UTC

there is understandable

then there is professional


It is true that it can be understood (IM speak)
It is also true that it is rather non-professional


SELECT CURSOR(..

abz, August 15, 2007 - 6:48 am UTC

I have a table t1, this table has 1 to many relation with
tables t2,t3. t2,t3 do not have any direct relation with eachother.

I have to read all data in all tables, what do you prefer
from the following. I am using 10g release 2 but if there
is some better way in 11g I can go for it also.

Also generalize this for t2,t3,t4,t5,... etc.

Method 1.
FOR i in (SELECT * FROM T1) LOOP
FOR j in (SELECT * FROM t2 WHERE t2.x=t1.x)LOOP
...process data...
END LOOP
FOR k in (SELECT * FROM t3 WHERE t3.x=t1.x)LOOP
...process data...
END LOOP
END LOOP;

Method 2
FOR i in
(SELECT t1.*,
CURSOR(select * from t2 where t2.x=t1.x),
CURSOR(select * from t3 where t3.x=t1.x)
FROM t1) LOOP
... process data...
END LOOP


Which one will be the faster and why.

Thanks
Tom Kyte
August 20, 2007 - 1:27 pm UTC

likely NEITHER of them

for i in
(select * from t1, t2 where join
 union all
 select * from t1, t3 where join )
loop
   process;
end loop;


You do not want to take what should be full scans and hash joins and force them to use an inefficient index as you would with your do it yourself joins.

plz reply to the above

abz, August 17, 2007 - 7:11 am UTC


Tom Kyte
August 22, 2007 - 9:12 am UTC

abz - tell you what - if you keep doing this "please reply" blah blah blah stuff, I'm going to start....

ignoring.


I sleep
I take time off to be with my kids
I'm actually taking time off from work right now
I'm not a machine
I answer that which I can
I do not respond to each and every one of these
I typically do get around to it (as I did above)

so, learn patience.

Anurag Arun Edlabadkar, August 17, 2007 - 7:15 am UTC

I want to fatch column value in row, please help me.

SELECT oeolv.header_id, oeolv.line_id, oeohv.order_number, oeohv.sold_to,
---oeolv.unit_selling_price,
-- jaistl.tax_amount, jaitc.tax_name,
DECODE (oeolv.ordered_item,
'Packing & Forwarding..', oeolv.unit_selling_price
) pnf,
DECODE (oeolv.ordered_item,
'FInished Item..', oeolv.unit_selling_price
) fnsed_item_unit_selling_price,
DECODE (oeolv.ordered_item,
'Freight Charge..', oeolv.unit_selling_price
) freight_charges,
DECODE (jaitc.tax_name, 'CED', jaistl.tax_amount) ced_amt,
DECODE (jaitc.tax_name,
'CED - Ed Cess', jaistl.tax_amount
) ced_ed_cess_amt,
DECODE (jaitc.tax_name,
'CED - SHE Cess', jaistl.tax_amount
) ced_she_cess_amt,
DECODE (jaitc.tax_name, 'VAT(4%)', jaistl.tax_amount) vat_amt --- ,
--, decode (oeolv.ORDERED_ITEM, 'Freight', oeolv.unit_selling_price) Freight
--, decode (oeolv.ORDERED_ITEM, 'FInished Item..' ,oeolv.TERMS)
FROM oe_order_headers_v oeohv,
oe_order_lines_v oeolv,
ja_in_so_tax_lines jaistl,
ja_in_tax_codes jaitc
WHERE oeohv.header_id = oeolv.header_id
AND oeohv.org_id = oeolv.org_id
AND jaistl.header_id = oeohv.header_id
AND jaistl.header_id = oeolv.header_id
AND jaistl.tax_id = jaitc.tax_id
-- AND jaistl.line_id = oeolv.line_id
AND oeohv.header_id = 1436
GROUP BY oeolv.header_id,
oeolv.line_id,
oeohv.order_number,
oeohv.sold_to,
oeolv.ordered_item,
oeolv.unit_selling_price,
jaitc.tax_name,
jaistl.tax_amount

Tom Kyte
August 22, 2007 - 9:13 am UTC

I
have
no
clue
what you mean by this.

then what good CURSOR are for?

abz, August 22, 2007 - 6:30 am UTC

Tom, Thanks for the answer.

1- I thought the CURSOR method would be faster, why you
think its not? can you please ellaborate it a little bit.
Otherwise, question arises , "for what good are cursor expressions then?".

2-Are you saying that the UNION ALL method is the
faster way to do it? if yes, then I would say
that UNION ALL may not work in all cases, because
there may/will be different no. of columns with different
datatypes in each query, although we can add NULL columns
whereever necessary to overcome this problem. Secondly
there will be different no. of rows in each query, how
will we know during processing that now we are starting
the dataset of the next query, although this can also be
overcome with adding a FLAG column indicating the query
from which the dataset belongs to.

Thanks
Tom Kyte
August 22, 2007 - 1:55 pm UTC

1) they would be useful for something like:

select d.*, cursor( select * from emp where emp.deptno = d.deptno ) emps,
cursor(select * from proj where proj.deptno = d.deptno) projs,
cursor( select * from bonus where bonus.deptno = d.deptno) bonuss
from dept d
where d.dname = 'SALES';

you are getting a small amount of data from the driving table (one row in my example), you need to get associated (but different number of columns/types) from a few others - and they all have a one to many relationship with the original source table.

So, instead of you writing code, we just do it in a single query - but I would not want to retrieve MILLIONS of records from dept and then have a cursor executed (three actually) for each row returned, that would be inefficient (to do a million index lookups on emp, on proj, on bonus). Then, I'd rather just join.


2) you can do the null trick or you can do three queries one after the other - six one way, half a dozen the other - in the grand scheme of things.

but I would NOT do the "do it yourself nested loops" trick you did - for lots of records - using indexes would be deadly.

abz, August 22, 2007 - 7:10 am UTC

Is there a lack of read consistency with a select
statement with CURSOR expressions. I mean when we fetch
from CURSOR expressions, is the row returned is as of
the time when the main select started ?


Tom Kyte
August 22, 2007 - 2:00 pm UTC

you would want to user serializable OR read only transactions

ops$tkyte%ORA10GR2> create table t as select * from all_users where rownum <= 1;

Table created.

ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> variable x refcursor
ops$tkyte%ORA10GR2> variable y refcursor
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> exec open :x for select t.*, cursor(select count(*) from t) from t;

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> exec open :y for select t.*, cursor(select count(*) from t) from t;

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> print x

USERNAME                          USER_ID CREATED   CURSOR(SELECTCOUNT(*
------------------------------ ---------- --------- --------------------
AOL                                   177 06-AUG-06 CURSOR STATEMENT : 4

CURSOR STATEMENT : 4

  COUNT(*)
----------
         1


ops$tkyte%ORA10GR2> declare
  2          pragma autonomous_transaction;
  3  begin
  4          delete from t;
  5          commit;
  6  end;
  7  /

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> print y

USERNAME                          USER_ID CREATED   CURSOR(SELECTCOUNT(*
------------------------------ ---------- --------- --------------------
AOL                                   177 06-AUG-06 CURSOR STATEMENT : 4

CURSOR STATEMENT : 4

  COUNT(*)
----------
         0




ops$tkyte%ORA10GR2> insert into t select * from all_users where rownum = 1;

1 row created.

ops$tkyte%ORA10GR2> commit;

Commit complete.

ops$tkyte%ORA10GR2> set transaction isolation level serializable;

Transaction set.

ops$tkyte%ORA10GR2> exec open :y for select t.*, cursor(select count(*) from t) from t;

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> declare
  2          pragma autonomous_transaction;
  3  begin
  4          delete from t;
  5          commit;
  6  end;
  7  /

PL/SQL procedure successfully completed.

ops$tkyte%ORA10GR2> print y

USERNAME                          USER_ID CREATED   CURSOR(SELECTCOUNT(*
------------------------------ ---------- --------- --------------------
AOL                                   177 06-AUG-06 CURSOR STATEMENT : 4

CURSOR STATEMENT : 4

  COUNT(*)
----------
         1


To abz

Michel Cadot, August 22, 2007 - 11:37 am UTC


Cursor is consistent with the time it is open.
That means that all rows (the result set) are defined at the moment you open the cursor.

Regards
Michel

Tom Kyte
August 22, 2007 - 2:18 pm UTC

ahh, but when you select a cursor... the cursor is opened by the client when it gets there....

see above.

Wow!

Michel Cadot, August 22, 2007 - 2:35 pm UTC


Indeed! I didn't think about this case.

Regards
Michel

anotherway to implentment null bindary

tomying, August 30, 2007 - 10:07 pm UTC

your sys_context is very useful to implentment the null bindary. but I wonder if nvl function is another way for this?

my database is oracle xe

set autotrace traceonly explain statistics;

drop table emp;
create table as emp select * from scott.emp;
alter table emp add constraint emp_pk primary key (empno);

variable x number;

select empno,deptno from emp where empno=nvl(:x,empno);


Plan hash value: 1180660262

----------------------------------------------------------------------------------------
| Id | Operation | Name | Rows | Bytes | Cost (%CPU)| Time |
----------------------------------------------------------------------------------------
| 0 | SELECT STATEMENT | | 17 | 442 | 3 (0)| 00:00:01 |
| 1 | CONCATENATION | | | | | |
|* 2 | FILTER | | | | | |
| 3 | TABLE ACCESS BY INDEX ROWID| EMP | 16 | 416 | 2 (0)| 00:00:01 |
|* 4 | INDEX FULL SCAN | EMP_PK | 16 | | 1 (0)| 00:00:01 |
|* 5 | FILTER | | | | | |
| 6 | TABLE ACCESS BY INDEX ROWID| EMP | 1 | 26 | 1 (0)| 00:00:01 |
|* 7 | INDEX UNIQUE SCAN | EMP_PK | 1 | | 0 (0)| 00:00:01 |
----------------------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------

2 - filter(:X IS NULL)
4 - filter("EMPNO" IS NOT NULL)
5 - filter(:X IS NOT NULL)
7 - access("EMPNO"=:X)

Note
-----
- dynamic sampling used for this statement


----------------------------------------------------------
225 recursive calls
0 db block gets
40 consistent gets
0 physical reads
0 redo size
620 bytes sent via SQL*Net to client
384 bytes received via SQL*Net from client
2 SQL*Net roundtrips to/from client
5 sorts (memory)
0 sorts (disk)
12 rows processed


AS we see ,the index is used .
Tom Kyte
September 04, 2007 - 6:00 pm UTC

for a single column sure.

for many - no - test it out, see what you see with three columns as I demonstrated...


cursor

Aru, October 09, 2007 - 12:06 am UTC

Hi Tom,
On our 10g database an alert comes up saying :-

Current Open Cursors - Count Metrics - "Current Open Cursors Count" is at 1252.

What is this? and how does it relate to the open_cursor init.ora parameter and how do I know what the upper limit is then and what/who is causing it to be so high. Normally it sits at around 300 - 500.
Regards,
ARU.

to tomying (anotherway to implentment null bindary )

Michal Pravda, December 12, 2007 - 10:54 am UTC

Hi,

your method "nvl" doesn't work. It skips rows with null values.

CREATE TABLE t
AS (SELECT decode (MOD(LEVEL, 2), 0, NULL, 'x') x , LEVEL lvl FROM dual CONNECT BY LEVEL <10);

SELECT * FROM t;

1 x 1
2 2
3 x 3
4 4
5 x 5
6 6
7 x 7
8 8
9 x 9


SELECT * FROM t
WHERE x = nvl(NULL, x);
1 x 1
2 x 3
3 x 5
4 x 7
5 x 9

MP

ps. when answering to someone's review I never know what to mark in the "How do you rate our response" field.
a) Tom's first followup
b) Tom's followup to review I am reviewing
c) The review itself
?

nvl

Michal Pravda, December 12, 2007 - 10:58 am UTC

I meant it doesn't work always. Of course it works in a case of a PK column. But with 3, 5, 10 columns, don't forget the NOT NULL constraint or you have a problem.

Determining the Number of Rows Returned by a Ref Cursor

John Gilmore, December 18, 2007 - 4:53 pm UTC

I'm returning a ref cursor, but I want to take some action based on the cardinality of the result set I'm returning.

open my_ref_cursor for
  select ...
  from my_tab
  where <my_conditions>;

Is there any way to find out the size of the result set apart from issuing a separate statement like the following prior to opening the ref cursor?

select count(*)
  into my_local_var
  from my_tab
  where <my_conditions>;

Tom Kyte
December 19, 2007 - 9:46 am UTC

even what you propose won't work

by the time your count(*) is done, the answer could easily have changed (other transactions and all you know)

the only way to know the cardinality of a result set is....

to retrieve the last record - unless and until you do that, even we don't know.



select * from one_hundred_billion_row_table;


that query starts returning data immediately, we do not "copy" the results anywhere, we fetch as you ask us to fetch.

You could use grouping sets - it'll add a TON OF WORK - as in A LOT OF WORK - to your typical query. so this would be something to do only on a) very small result sets b) only if there is absolutely and completely NO OTHER WAY to achieve your goal.

say you wanted to execute

select ename, empno, deptno from emp where ename like '%A%' order by ename



you would instead query
   select ename, empno, deptno, count(*)
     from scott.emp
     where ename like '%A%'
     group by grouping sets( (), (ename,empno,deptno) )
     order by grouping(ename) DESC, ename;


there would be an extra row in this result set (I am also assuming that ename, empno, deptno is UNIQUE - if not, you will get those rows collapsed and the count will be there to tell you how many rows they represent - if you needed to keep the rows separate, just add something unique to the select group by list - like rowid in this case)


ops$tkyte%ORA11GR1> variable x refcursor
ops$tkyte%ORA11GR1>
ops$tkyte%ORA11GR1> declare
  2      l_cursor sys_refcursor;
  3      l_ename  scott.emp.ename%type;
  4      l_empno  scott.emp.empno%type;
  5      l_deptno scott.emp.deptno%type;
  6      l_cnt    number;
  7  begin
  8      open l_cursor for
  9    select ename, empno, deptno, count(*)
 10      from scott.emp
 11     where ename like '%A%'
 12     group by grouping sets( (), (ename,empno,deptno) )
 13     order by grouping(ename) DESC, ename;
 14
 15      fetch l_cursor into l_ename, l_empno, l_deptno, l_cnt;
 16      if (l_cursor%notfound)
 17      then
 18          l_cnt := 0;
 19      end if;
 20      dbms_output.put_line( 'we will get ' || l_cnt || ' rows...' );
 21
 22      :x := l_cursor;
 23  end;
 24  /
we will get 7 rows...

PL/SQL procedure successfully completed.

ops$tkyte%ORA11GR1> print x

ENAME           EMPNO     DEPTNO   COUNT(*)
---------- ---------- ---------- ----------
ADAMS            7876         20          1
ALLEN            7499         30          1
BLAKE            7698         30          1
CLARK            7782         10          1
JAMES            7900         30          1
MARTIN           7654         30          1
WARD             7521         30          1

7 rows selected.


the first row is for you, the second - nth rows for them.

Incorrect assumption about combinations by a reader

Robert, December 20, 2007 - 10:49 pm UTC

A reader wrote as part of their reply about building dynamic search queries:

"If I use dynamic SQL using the sys_context approach you demonstrate above, I would end up with
(potentially) a factorial (or some high combinatorial number) based on 8 distinct SQLs (even if I
use bind variables for each of the searchable fields)"

This statement is just wholly incorrect.

.. A AND B is no different to B AND A.

Just on this topic of Dynamic SQL and stored procedures, it is often debated, namely by procedural programmers (C#, Java) about whether to use Dynamic SQL or Stored Procedures to solve a particular problem. The problem with this idea is that the two terms cannot be compared, for it's illogical to do so. It's like saying what is better: The AND or the OR operator.

If the best solution is to use Dynamic SQL then simply, use Dynamic SQL. On the other hand, if you can write the query at design time, then do so. Stored Procedures are NOT an alternative to Dynamic SQL, they are where you indeed write the code. Forgive me, but why people often try to compare the two. The two concepts are in no way related.

Having read the earlier comment, I just felt compelled to clarify this point.

Thank you.

Problem with l_template%rowtype

Shah Nawaz, March 26, 2008 - 11:58 pm UTC

Hi Tom,
Original Message from you -->>
=========================================================
ops$tkyte@ORA8I.WORLD> create or replace
2 procedure my_procedure( p_ename in varchar2 default NULL,
3 p_hiredate in date default NULL,
4 p_sal in number default NULL)
5 as
6 type rc is REF CURSOR;
7
8 l_cursor rc;
9 l_query varchar2(512)
10 default 'select * from emp where 1 = 1 ';
11
12 cursor l_template is select * from emp;
13 l_rec l_template%rowtype;
14

Here I use what I call a "TEMPLATE" cursor. I like to use these with my ref cursors.
I use them to define a record to fetch into. Here, in this simple example, I could have
skipped it and just defined l_rec as EMP%rowtype -- but I wanted to show how this would
work if you didn't select * from a single table but had many columns from many tables.
This just helps me create a nice record. The template query ONLY has a SELECT and a
FROM. I never put a WHERE clause on it (even when joining) since I never use it any
where. I just use it to get the default datatypes, names and so on for a record
definition right below it.
=========================================================--<<
Hi Tom as you mentioned above that we can use l_template%rowtype for other tables also.

My Problem is -->
I have a procedure, to which i passed "Table_Name" as parameter, It reads a custom table and picks "Select_Column_List" and "Where_Clause"
In custom table there are different table_Names and Different Number of columns
Like
Tab1 col1,col2,col3
Tab2 col1,col2,col3,col4,col5,col6
Tab3 col1,col2,col3,col4

That means when i pass "Tab1" to my procedure, my dynamic cursor will be
Open Dynamic cursor for (Select col1,col2,col3 from Tab1)

when i pass "Tab2" to my procedure, my dynamic cursor will be Open Dynamic cursor for (Select col1,col2,col3,col4,col5,col6 from Tab2)

BUT I CAN NOT FETCH IT INTO ANY VARIABLE AS EVERYTIME DynamicCursor%rowtype is different ( I can not use tab1%rowtype as i am selecting "ALL" columns)

Is there any way to use your suggested method of defining
template in this scenerio as u mentioned above
cursor l_template is select * from emp;
l_rec l_template%rowtype;

Tom Kyte
March 27, 2008 - 10:37 am UTC

until 11g - if you want to process this as a ref cursor - you will NOT be processing the ref cursor in PLSQL

if you want to process the result set in plsql, you MUST use dbms_sql - dbms_sql can procedurally access the result set.

in 11g, we can convert a ref cursor into a dbms_sql cursor number, allowing us to procedurally process it (so in 11g, you will STILL be using dbms_sql, but you can open the cursor as a ref cursor)


substitution variables in REF cursor

Vikram Rathore, April 09, 2008 - 5:58 am UTC

Tom,

We have a lot of web based dynamic reports in one of our system. The users enter their parameters using a parameter screen and then REF cursors are used to create the dynamic queries.

I have modified the original MY_PROCEDURE that you have given at the start of this thread. It used the techniques that are currently being used in our project.

Please see the code below
create or replace
procedure my_procedure( p_ename in varchar2 default NULL,
p_hiredate in date default NULL,
p_sal in number default NULL)
as
type rc is REF CURSOR;

l_cursor rc;
l_query varchar2(512)
default 'select * from emp where 1 = 1 %w_ename %w_hiredate %w_sal';

l_ename varchar2(512);
l_hiredate varchar2(512);
l_sal varchar2(512);

cursor l_template is select * from emp;
l_rec l_template%rowtype;
begin

if ( p_ename is NOT NULL ) then

l_ename := ' AND ename LIKE #'||'%'||upper(p_ename)||'%#';

l_query := REPLACE(l_query,'%w_ename',l_ename);
else
l_query := REPLACE(l_query,'%w_ename');
end if;

if ( p_hiredate is NOT NULL ) then

l_hiredate := ' AND hiredate > to_date(to_char('||p_hiredate||',yyyymmddhh24miss#),#yyyymmddhh24miss#)';
l_query := REPLACE(l_query,'%w_hiredate',l_hiredate);
else
l_query := REPLACE(l_query,'%w_hiredate');
end if;

if ( p_sal is NOT NULL ) then
l_sal := 'AND sal > ' || p_sal;
l_query := REPLACE(l_query,'%w_sal',l_sal);
else
l_query := REPLACE(l_query,'%w_sal');
end if;

l_query := REPLACE(l_query,'#',CHR(39));

p( l_query );

open l_cursor for l_query;

loop
fetch l_cursor into l_rec;
exit when l_cursor%notfound;

dbms_output.put_line( l_rec.ename || ',' ||
l_rec.hiredate || ',' ||
l_rec.sal );
end loop;

close l_cursor;
end;
/

Procedure created.


Can you please give your comments on this. Specially from a performance point of view. The problem is that we also construct the from clause dynamically in most of the queries.

If this is not a good practise can you also suggest alternatives.
Tom Kyte
April 09, 2008 - 2:51 pm UTC

i don't have any idea why you did the % replace trick, it was not necessary.

so, why?

ref cursor performance

Vikram Rathore, April 10, 2008 - 4:03 am UTC

Tom,

The % variable substitution technique is not something that I introduced it was an ingoing practise.

However, now that we have new developments starting I wanted you view from a performance perspective.

So, my question is which REF cursors will function better in a multiuser environment..... The one's that use the % substitution technique or the one's that use SYS_CONTEXT()?

Thanks
Vikram
Tom Kyte
April 10, 2008 - 10:45 am UTC

... The % variable substitution technique is not something that I introduced it was
an ingoing practise.
...

sure it was something YOU introduced to MY code - since I would not do that.


using 'substitution' stuff to me implied "no binds", "no binds" means "I don't like your code at all"

I've already demonstrated with working code what I deem to be the correct approach above and it does not employ using 'replace' on a sql statment to glue in user supplied input.

it BINDS

Fine Grained Access Control with Application Contexts

Fábio Oliveira, April 17, 2008 - 9:39 am UTC

Hi Tom,

this thread is great. I was looking for exactly this for over a month.
Today I've found something interesting on this article of yours http://asktom.oracle.com/tkyte/article2/index.html What about using Fine Grained Access Control with Application Contexts to achieve this same results? It surely is a workaround without the appropriate tools but what do you think?

My idea is to build a view, set the security policies and decide which conditions to use based on the Application Context.

What about performance on this approach of mine? I'm asking this because performance is the most important aspect of my actual project.
Tom Kyte
April 17, 2008 - 11:46 am UTC

well, this page is "how to dynamically construct a query that stands a chance of performing"

Not sure why you would want to obscure it via find grained access control - how would a magic select * from view - that writes a predicate no one can "see" - be desirable?

I see it being hard to debug, maintain, tune, understand - too much "magic" happening.

Fábio Oliveira, April 18, 2008 - 4:26 am UTC

Thanks for your previous answer.
I've liked this solution mainly because I have multiple search screens and all this dynamic SQL is making all the code unreadable, unpractical to mantain and, I'm afraid, nonperforming.

My idea with views is something like this:

--Have a view for each search (this is a simple view example)
CREATE VIEW get_search_1_v AS
SELECT a.x, a.y, b.z
FROM a, b
WHERE a.w = 'foo';

-- Have a security function (I can use one function on all views)
create function my_security_function( p_schema in varchar2,
p_object in varchar2 ) return varchar2
as
context_v varchar2(4000);
condition varchar2(4000);
begin
-- function that gives me the context var name and condition to use
if not get_context(i_view_name => p_object,
o_context_var => context_v,
o_condition => condition) then
return '';
end if;
if ( sys_context('MY_CTX', context_v) is null ) then
return '';
else
-- any condition ( a.y = sys_context('MY_CTX', 'VAR_1') )
return := condition;
end if;
end;

-- Here I set the policy to my view but I can set the same policy to all my search views
begin
dbms_rls.add_policy
( object_name => 'get_search_1_v',
policy_name => 'MY_POLICY',
policy_function => 'my_Security_Function',
statement_types => 'select' ,
update_check => TRUE );
end;
/

Now, everytime I want to do a search I just have to set the context with the value I want to filter on field a.y.
This ends with all the dynamic SQL and everyone that desires to change the search query only needs to change the view and, maybe, it's conditions.

Now, what I don't know is two things:
how is this going to performance against the dynamic SQL option?
can I set multiple conditions on the security function, like returning 'a.y = 2 and b.z > 3'?

Thanks in advance,
Fábio Oliveira
Tom Kyte
April 18, 2008 - 10:18 am UTC

ummm, how would dynamically constructing a where clause in a policy function...

instead of in function "x"

solve

...
all the code unreadable, unpractical to mantain and,
I'm afraid, nonperforming.
....

you would have the same thing at the end - a function that dynamically builds a where clause.


Quick opinion?

Greg, June 02, 2008 - 10:02 am UTC

I did some searches, but couldn't find a perfect match for this, I hope this is on-topic enough ..

Just curious, what is your opinion on this "style":

FOR a IN ( SELECT something FROM somewhere )
LOOP
lvar := a.something;
EXIT;
END;

My thoughts are, do this instead:

BEGIN
SELECT something
INTO lvar
FROM somewhere
WHERE rownum = 1;
EXCEPTION
WHEN no_data_found THEN
NULL; -- might not care about this case, do whatever
END;

From what I've understood, this works "more better" ?
(ie less overhead, slightly faster ... etc?)

Or am I way off base?

(alternately, if you needed a specific record, say the latest one:
SELECT something
INTO lvar
FROM ( SELECT something,
row_number() OVER
(order by somedate DESC) rnum
FROM somewhere
)
WHERE rnum = 1;
)


Just curious as to your opinion with these options and which you feel performs better, easier to maintain/read ??

Thanks!!
Tom Kyte
June 02, 2008 - 11:48 am UTC

BEGIN
  SELECT something
    INTO lvar
    FROM somewhere
   WHERE rownum = 1;
EXCEPTION
  WHEN no_data_found THEN
     NULL;  -- might not care about this case, do whatever
END;



that bit of code shows that you actually MEANT to do what you are doing. It is the correct approach.

However, it shows something else - which is - you don't know that you don't need to do the select at all.

of what possible use is "give me the first random record"????



True Enough

Greg, June 06, 2008 - 9:03 am UTC

"of what possible use is "give me the first random record"???? "

I do agree with you on this ... (when I write this, I typically use the 2nd query with the subquery ordering it, at least I know which row I'm getting .. ie "latest one", "largest one", "smallest one" .. whatever ...

I know it doesn't make it right, but I often see the "random" option used due to "not-so-quite-correct" data .. (and a business that doesn't allow you to fix old/bad data that easily ... especially when they think it isn't bad ..) *sigh*

Thank-you for your thoughts and time on this ...
Tom Kyte
June 09, 2008 - 9:55 am UTC

.... I know it doesn't make it right, but I often see the "random" option used due
to "not-so-quite-correct" data .. (and a business that doesn't allow you to fix
old/bad data that easily ... especially when they think it isn't bad ..) ....

ouch, that hurt my head to read.

cursor

A reader, June 24, 2008 - 4:52 pm UTC


Session contexts with shared connections

John Rager, July 03, 2008 - 5:25 pm UTC

Hi Tom,

This is in reference to the earlier post, "Session contexts with shared connections" in this topic.

When using mod_plsql for our Web apps where the application server is controlling connection grabbing and sharing, how can we ensure that two users working virtually simultaneously won't overwrite each others sys_context settings sometime between when the code starts evaluating parameters and building l_query, and executing the query?

Thanks,
John
Tom Kyte
July 07, 2008 - 10:22 am UTC

mod_plsql works by

a) getting url, like /pls/dcd/foobar

b) parsing it, dcd is used to figure out what database to use

c) running foobar from start to finish.


foobar is run as a single statement - it generates the entire page from start to finish. There is zero chance of that foobar procedure using two sessions to run in.


foobar would:

a) set context
b) build l_query
c) execute it and print the answer.
d) then return.....



Session contexts with shared connections

John Rager, July 07, 2008 - 12:00 pm UTC

Thanks Tom. Just to be sure I'm understanding correctly: assuming I go by your my_procedure example up at the top, can I be certain that everything that runs within the procedure runs as though it's one statement and the sys_context variables will be "protected" while the procedure runs?
Tom Kyte
July 07, 2008 - 12:15 pm UTC

the stored procedure run by mod_plsql run run from start to finish. So yes, it would be "protected", it is in fact a single call to the server.

Session contexts with shared connections

John Rager, July 07, 2008 - 1:11 pm UTC

Thanks so much for your helpful advice Tom.

Cursor

Reader, July 07, 2008 - 4:19 pm UTC

Hi Tom

Just read the original question and first response. Fantastic! What an informative response!

So useful!

Regards

Performance issues and such...

Itai, July 20, 2008 - 3:54 am UTC

hi tom, I started a new job using oracle a few weeks ago, and this dynamic select procedure was one of the first things that popped to mind. this thread has been most helpful.

however, I am concerned about performance...
will using sys_context with DNS be slower (much slower?) than just writing a simjavascript:doSubmit('SUBMIT_REVIEW')
Submit Reviewple select for each case needed?

and in general - what are the downsides of using such a method to perform selects on tables? am I likely to face evil-eye looks from the DBAs if I ask to create a context for each table and write a generic GetBy procedure for each one?

thanks.
Tom Kyte
July 22, 2008 - 10:06 am UTC

.... will using sys_context with DNS be slower (much slower?) than just writing a
simjavascript:doSubmit('SUBMIT_REVIEW')
Submit Reviewple select for each case needed?
...

I do not understand that question at all.

sys_context is not "slow", it works much like a bind variable would. It reduces the number of unique sql statements that have to be hard parsed - hard parsing is a KILLER on a system that does a lot of sql - it takes only one unbound sql statement executed frequently enough (a couple of times a minute would do it) to really kill a shared pool.

you need to create ONE context, why create one for each table?!?

But you would never create an API for each table, your queries involve joining don't they? do not write "get and set" API's table by table, do things in bulk, using joins - do not think "tables", think "entire answers to questions"

dynamic tables

A reader, August 11, 2008 - 3:01 am UTC

hey tom, I understand and feel your passion for bind variables, but what about dynamic table names?

I found myself needing to do something like:
'select * from ' || table_name_var;

obviously, this code would be subject to SQL injection. I tried using sys_context here but that's no good either.
my current thought of securing the code is to check (using bind variables) that the table name actually exists in the database:
'select * from all_tables where table_name = sys_context(''my_ctx'', ''table_name_var'');

so that I know the string is really a valid table name and not some attack code.
what do you think of this method? can you suggest a better one?

thanks.
Tom Kyte
August 12, 2008 - 8:21 am UTC

you can use dbms_assert and this quick check on the dictionary to verify the correctness of the inputs, yes.

More options

Sanjeev Chauhan, November 18, 2008 - 5:02 pm UTC

I would like to share a couple of other methods for using bind variables with dynamic queries when the number of bind values is unknown. I would greatly appreciate your comment on these approaches. This question has been asked in several places, so I am not sure if this the correct place for this post

create table t_dyn as
select rownum num
     , 'x'||mod(rownum, 1000) vc2
     , trunc(sysdate)+mod(rownum,1000) dt
from dual
connect by level <= 10;

create or replace
  function alt1 (    
      p_num in number default null,
      p_vc2 in varchar default null,
      p_dt  in date default null
  )
  return sys_refcursor
  as    
    l_rc sys_refcursor;    
    l_qry varchar2(256) := 
        'select t.num' || chr(10) ||
        '     , t.vc2' || chr(10) ||
        '     , t.dt' || chr(10) ||
        'from   t_dyn t' || chr(10) ||
        'where  1=1' || chr(10);
  begin
      if p_num is null then
        l_qry := l_qry ||'and    -1 = :bv_num' || chr(10);
      else        
        l_qry := l_qry ||'and    t.num = :bv_num' || chr(10);
      end if;
      
      if p_vc2 is null then
        l_qry := l_qry ||'and    ''x'' = :bv_vc2' || chr(10);
      else
        l_qry := l_qry ||'and    t.vc2 = :bv_vc2' || chr(10);
      end if;
      
      if p_dt is null then
        l_qry := l_qry ||'and    sysdate = :bv_dt';
      else
        l_qry := l_qry ||'and    t.dt = :bv_dt';
      end if;
      
      open l_rc for l_qry 
          using nvl(p_num, -1)
              , nvl(p_vc2, 'x')
              , nvl(p_dt, sysdate)
              ;
      
      return l_rc;
  end alt1;
/ 
create or replace
  function alt2 (    
      p_num in number default null,
      p_vc2 in varchar default null,
      p_dt  in date default null
  )
  return sys_refcursor
  as    
    l_rc sys_refcursor;    
    l_qry varchar2(256) := 
        'select t.num' || chr(10) ||
        '     , t.vc2' || chr(10) ||
        '     , t.dt' || chr(10) ||
        'from   t_dyn t' || chr(10) ||
        '   ,   ( select :p_num as bv_num' || chr(10) ||
        '              , :p_vc2 as bv_vc2' || chr(10) ||
        '              , :p_dt  as bv_dt' || chr(10) ||
        '         from dual ) x'  || chr(10) ||
        'where  1=1' || chr(10);
  begin
      if p_num is not null then
        l_qry := l_qry ||'and    t.num = x.bv_num' || chr(10);
      end if;
      
      if p_vc2 is not null then
        l_qry := l_qry ||'and    t.vc2 = x.bv_vc2' || chr(10);
      end if;
      
      if p_dt is not null then
        l_qry := l_qry ||'and    t.dt = x.bv_dt';
      end if;
      
      open l_rc for l_qry using p_num, p_vc2, p_dt;
      
      return l_rc;
  end alt2;
/

Tom Kyte
November 21, 2008 - 3:18 pm UTC

Instead of
      if p_num is null then
        l_qry := l_qry ||'and  <b>  -1 = :bv_num</b>' || chr(10);
      else        
        l_qry := l_qry ||'and    t.num = :bv_num' || chr(10);
      end if;



I think you mean
      if p_num is null then
        l_qry := l_qry ||'and </b>:bv_num IS NULL</b>' || chr(10);
      else        
        l_qry := l_qry ||'and    t.num = :bv_num' || chr(10);
      end if;


and then

open l_rc for l_qry 
          using p_num
              , p_vc2
              , p_dt;


since a number could be -1, a string could be 'x' and sysdate is being evaluated in two different places (eg: the date 'trick' you tried is definitely flawed - sysdate evaluated during the nvl() could be different from the sysdate evaluated during the open of the cursor...


I'd prefer that over the join.

Why not Cursor parameter?

Karthik, November 20, 2008 - 5:57 am UTC

Tom,

The original question posted says that the body of the cursor will be the same except for the where clause. In this case, why shouldn't we use cursor with parameter instead of Ref cursor ?
Tom Kyte
November 24, 2008 - 11:31 am UTC

... except for the where clause. ...

except for the where clause - so we could have


o 1 with NO where clause (all inputs null)
o 3 with a single predicate
o 3 with "pairs" of predicate conditions
o 1 with all three predicate conditions


I don't want to have to code 8 queries (think about when you go to 4 inputs, or 5 inputs) and have a big if/else or case block to find the right one (the if statements alone would be heinous to code

if ( a is null and b is null and c is null )
elsif ( a is not null and b is null and c is null )
elsif ( a is null and b is not null .......)

sys_context and bind variables

A reader, December 08, 2008 - 3:13 pm UTC

If I'm looking at the trace files, how can I tell that bind variables are being used when I use sys_context?
Tom Kyte
December 09, 2008 - 1:14 pm UTC

sys_context works like a bind, it is not a bind, it works LIKE a bind.

http://docs.oracle.com/docs/cd/B19306_01/network.102/b14266/apdvpoli.htm#i1006499

A reader, January 07, 2009 - 11:55 am UTC

Can I use a regular table the same way you use sys_Context in place of bind variables? Would it achieve the same effect?

Tom Kyte
January 07, 2009 - 2:57 pm UTC

sure, you can use a scalar subquery to return the value

select * from t where x = sys_context( 'my_ctx', 'my_val' )

would be like:

select * from t where x = (select val from my_table where name = 'my_val');


Required privilege security?

Stew, January 07, 2009 - 12:17 pm UTC

I often have the need to support queries like this that may include a variable number of parameter matches, so I was interested to try this approach when I just found it.

But my first step failed, as I don't have the needed CREATE ANY CONTEXT system privilege on our system. Before I ask our DBAs to grant it, can you think of any major security risks that granting this privilege would cause? All programmers have rights (on our test system) to create tables, packages, types, etc. We have a lead programmer who deploys our code to production and he has those rights there.

Thanks for the great write-up.
Tom Kyte
January 07, 2009 - 3:02 pm UTC

You should not have it, they should create the context for you. And the account that deploys to production would have it.

There are serious issues with all of the ANY privileges.

application contexts are typically used with SECURITY (fine grained access control), if you have the create any context privilege, you would be able to reset the context procedure and possibly gain access to information you should not have.

Conditional where clause

Salman Syed, February 24, 2009 - 11:32 am UTC

Tom,

Here is the simplified problem. On a per user basis, we have a setting show_only_primary_owner (
select show_only_primary_owner from employee where employee_id = :x 
). When that is set to 1, I have I have to append an extra where clause (is_primary_owner = 1) onto about 40 queries which will grow in the future.

So the two separate queries are:

select * from opportunity o where o.opportunity_id in
(select opportunity_id from opportunity_team where employee_id = :x
and is_primary_owner = 1)

and 


select * from opportunity o where o.opportunity_id in
(select opportunity_id from opportunity_team where employee_id = :x)



One way to do it would be to write separate SQL statements for the two cases but that leads to code duplication and maintenance problems.

However, I want to be able to write one SQL that satisfies both conditions to reduce the SQL code we will have to maintain by half.

So I know I can use dynamic SQL. However, as you have shown, there is considerably more latching going on when using Dynamic SQL.

Is there anything else I could look into?

I tried to do a variable inlist. Since is_primary_owner can only have the values 0 or 1, I wrote this query:
with q as (select case when show_only_primary_owner = 1 then '1' else '0,1' end val
           from employee e where e.employee_id = :x)
           
select * from opportunity o,q where o.opportunity_id in
(select opportunity_id from opportunity_team where employee_id = :x
and is_primary_owner in (select * from table(pkg_query_optimization.func_str_to_tbl(q.val)) where rownum >=0));


However, this query takes more CPU time. Is there anything you can suggest that I can look at? What would be your approach?

Thanks!
Tom Kyte
February 24, 2009 - 5:11 pm UTC

select * 
  from opportunity o 
 where o.opportunity_id in
   (select opportunity_id 
      from opportunity_team 
     where employee_id = :x
       and (is_primary_owner = :y or :y is null))



I assume you have an index on employee_id
I assume you want that index to be used

I assume that is_primary_owner would be a filter after index is applied.
I assume that is_primary_owner is nullable.

If my assumptions hold true, the above query will satisfy your needs, bind a value of 1 or NULL for Y.

If is_primary_owner is nullable, this can be written

select * 
  from opportunity o 
 where o.opportunity_id in
   (select opportunity_id 
      from opportunity_team 
     where employee_id = :x
       and is_primary_owner = nvl(:y,is_primary_owner) )



You also have the ability to:

is
   l_query sys_refcursor;
   ...

begin
   if (condition) 
   then
      open l_query for select * from opportunity o where o.opportunity_id in
(select opportunity_id from opportunity_team where employee_id = :x
and is_primary_owner = 1)
   else
      open l_query for select ....
   end if;
 

   fetch l_query into ...

Awesome stuff!

Salman Syed, February 25, 2009 - 3:11 pm UTC

Tom,

Awesome solution! Never thought how one could take advantage of (not nullable column) = null!

The is_primary_owner is currently not nullable and can only have the values 0,1. So, the first query will work perfectly. (Just as a minor note, you wrote: I assume that is_primary_owner is nullable. I think what you meant to say was: I assume that is_primary_owner is not nullable. Please correct me if I am wrong because then my understanding of the solution is not correct).

Tom Kyte
February 25, 2009 - 6:18 pm UTC

the second query is the one you want, but you are correct, where I wrote:

If my assumptions hold true, the above query will satisfy your needs, bind a value of 1 or NULL for Y.

If is_primary_owner is NOT (added) nullable, this can be written

select * 
  from opportunity o 
 where o.opportunity_id in
   (select opportunity_id 
      from opportunity_team 
     where employee_id = :x
       and is_primary_owner = nvl(:y,is_primary_owner) )




I'm not taking advantage of not null = null, that concept doesn't exist.


If is_primary_owner is nullable, then:

select * 
  from opportunity o 
 where o.opportunity_id in
   (select opportunity_id 
      from opportunity_team 
     where employee_id = :x
       and (is_primary_owner = :y or :y is null))


is what you want, :y := 1 gets you is_primary_owner = 1, :y := NULL gets you every record regardless (eg: you set :y to NULL to not have this predicate, you set it to 1 to have this predicate)


A short cut if is_primary is NOT NULL would be:

select * 
  from opportunity o 
 where o.opportunity_id in
   (select opportunity_id 
      from opportunity_team 
     where employee_id = :x
       and is_primary_owner = nvl(:y,is_primary_owner) )


and again, set :y to 1 or NULL, if :y = 1, nvl() returns 1, else nvl() returns the column value of the current row and since none of them are NULL, that just becomes "is_primary = is_primary" which would always be true.

Can't use application context

Joe Simunac, March 09, 2009 - 2:43 pm UTC

Your solution to building the WHERE clause is exactly what I need in my situation. However, our DBAs will not grant privileges to create an application context for security reasons. Is there another way to solve this problem without using an application context and also without hard coding all the possible queries?
Tom Kyte
March 09, 2009 - 4:00 pm UTC

http://asktom.oracle.com/pls/asktom/f?p=100:11:0::::P11_QUESTION_ID:1288401763279#4988761718663

shows another very valid way, the optimizer will optimize it away as a filter.

Is dynamic refcursor faster?

ora dev, May 03, 2009 - 1:11 pm UTC

Tom, Thank you so much for the wonderful teaching you are doing. Have questions regarding the set_context approach:
1) Can we say from below that dynamic sql with USING is better than set_context approach because of less latches and less time(though it uses UGA and PGA memory)

Connected to:
Oracle Database 10g Enterprise Edition Release 10.2.0.4.0 - 64bit Production
With the Partitioning, Data Mining and Real Application Testing options

SQL> create or replace procedure dyn_refcursor(p_sal   number,p_date   date)
  2  as
  3    type ref_cur is ref cursor;
  4    cur_ref   ref_cur;
  5    l_query   varchar2(32767);
  6    vd_date   date;
  7    vn_sal    emp.sal%type;
  8    emp_rec   emp%rowtype;
  9  begin
 10    for i in 1..1000
 11    loop
 12        l_query := 'select * from emp where 1 = 1 ';
 13  
 14        vn_sal  := p_sal;
 15        vd_date := p_date;
 16  
 17        if ( vn_sal is NOT NULL ) then
 18            l_query := l_query || ' and sal > :vn_sal ';
 19        else
 20            vn_sal  := 0;
 21            l_query := l_query || ' and 0 = :vn_sal';
 22        end if;
 23  
 24        if (vd_date is NOT NULL ) then
 25            l_query := l_query || ' and hiredate < :vd_date';
 26        else
 27            vd_date := to_date('01-jan-1900','dd-mon-yyyy');
 28            l_query := l_query || ' and to_date(''01-jan-1900'',''dd-mon-yyyy'') = :vd_date';
 29        end if;
 30  
 31        open cur_ref for l_query USING vn_sal,vd_date;
 32        close cur_ref;
 33    end loop;
 34  end;
 35  /

Procedure created.

SQL> 
SQL> create or replace procedure ctx_refcursor(p_sal   number,p_date  date)
  2  as
  3    type ref_cur is ref cursor;
  4    cur_ref   ref_cur;
  5    l_query   varchar2(32767);
  6    emp_rec   emp%rowtype;
  7  begin
  8    for i in 1..1000
  9    loop
 10  
 11        l_query := 'select * from emp where 1 = 1 ';
 12  
 13        if ( p_sal is NOT NULL ) then
 14            dbms_session.set_context( 'REFCUR_CTX','SAL',p_sal);
 15            l_query := l_query || ' and sal > to_number(sys_context( ''REFCUR_CTX'', ''SAL'' ))';

 16        end if;
 17  
 18        if ( p_date is NOT NULL ) then
 19            dbms_session.set_context( 'REFCUR_CTX','HIREDATE',to_char(p_date,'dd-mon-yyyy'));
 20            l_query := l_query || ' and 
 21                                    hiredate < 
 22                                    to_date(sys_context( ''REFCUR_CTX'', ''HIREDATE'' ),''dd-mon-
yyyy'')';
 23        end if;
 24  
 25        open cur_ref for l_query;
 26        close cur_ref;
 27    end loop;
 28  end;
 29  /

Procedure created.

SQL> exec runStats_pkg.rs_start;

PL/SQL procedure successfully completed.

SQL> exec dyn_refcursor(1100,TO_DATE ('1-jan-1982','DD-mon-YYYY'));

PL/SQL procedure successfully completed.

SQL> exec runStats_pkg.rs_middle;

PL/SQL procedure successfully completed.

SQL> exec ctx_refcursor(1100,TO_DATE ('01-jan-1982','dd-mon-YYYY'));

PL/SQL procedure successfully completed.

SQL> exec runStats_pkg.rs_stop;

PL/SQL procedure successfully completed.


Run1 ran in 82 hsecs
Run2 ran in 148 hsecs
run 1 ran in 55.41% of the time
......
LATCH.enqueues 76 0 -76
LATCH.enqueue hash chains 93 0 -93
LATCH.shared pool simulator 2,016 22 -1,994
LATCH.library cache lock 11 4,004 3,993
LATCH.library cache pin 32 4,028 3,996
LATCH.library cache 49 6,041 5,992
STAT...session uga memory 0 65,408 65,408
STAT...session pga memory 0 65,536 65,536

Run1 latches total versus runs -- difference and pct
Run1 Run2 Diff Pct
2,596 14,475 11,879 17.93%

2) Can we say from below the dynamic refcursor is faster than static refcursor and use that for performance even though dynamic code is tough to write/maintain. Static is doing soft parse and dynamic one is doing softer soft parse.

SQL> create or replace procedure stat_refcursor1
  2  as
  3    type ref_cur is ref cursor;
  4    cur_ref      ref_cur;
  5    vn_sal       pls_integer := 1100;
  6    vd_hiredate  date := TO_DATE ('1/1/1982','MM/DD/YYYY');
  7  BEGIN
  8    for i in 1..1000
  9    loop
 10       open cur_ref for
 11          SELECT * FROM EMP WHERE SAL > vn_sal AND HIREDATE < vd_hiredate;
 12       close cur_ref;
 13    end loop;
 14  END;
 15  /

Procedure created.

SQL> 
SQL> create or replace procedure dyn_refcursor_1
  2  as
  3    type ref_cur is ref cursor;
  4    cur_ref      ref_cur;
  5    vn_sal       pls_integer := 1100;
  6    vd_hiredate  date := TO_DATE ('01-jan-1982','dd-mon-yyyy');
  7  BEGIN
  8    for i in 1..1000
  9    loop
 10       open cur_ref for
 11          'SELECT * FROM EMP WHERE SAL > :vn_sal AND HIREDATE < :vd_hiredate'
 12          USING vn_sal,vd_hiredate;
 13       close cur_ref;
 14    end loop;
 15  END;
 16  /

Procedure created.

SQL> 
SQL> exec runStats_pkg.rs_start;

PL/SQL procedure successfully completed.

SQL> exec stat_refcursor1;

PL/SQL procedure successfully completed.

SQL> exec runStats_pkg.rs_middle;

PL/SQL procedure successfully completed.

SQL> exec dyn_refcursor_1;

PL/SQL procedure successfully completed.

SQL> exec runStats_pkg.rs_stop;

Run1 ran in 79 hsecs
Run2 ran in 76 hsecs
run 1 ran in 103.95% of the time
......
LATCH.object queue header oper 12 0 -12
LATCH.object queue header heap 12 0 -12
LATCH.JS queue state obj latch 36 0 -36
LATCH.checkpoint queue latch 48 96 48
LATCH.cache buffers chains 186 135 -51
LATCH.enqueue hash chains 77 19 -58
LATCH.SQL memory manager worka 6 73 67
STAT...undo change vector size 2,260 2,332 72
LATCH.enqueues 76 2 -74
STAT...redo size 3,040 3,124 84
LATCH.shared pool 1,002 2 -1,000
STAT...session cursor cache hi 4 1,004 1,000
LATCH.library cache 4,041 47 -3,994
LATCH.library cache lock 4,008 6 -4,002

Run1 latches total versus runs -- difference and pct
Run1 Run2 Diff Pct
11,736 2,579 -9,157 455.06%

And if softer soft parses are disabled then also dynamic refcursor is having far less latches.

SQL> alter session set session_cached_cursors = 0;

Session altered.

SQL> exec runStats_pkg.rs_start;

PL/SQL procedure successfully completed.

SQL> exec stat_refcursor1;

PL/SQL procedure successfully completed.

SQL> exec runStats_pkg.rs_middle;

PL/SQL procedure successfully completed.

SQL> exec dyn_refcursor_1;

PL/SQL procedure successfully completed.

SQL> exec runStats_pkg.rs_stop;



Run1 ran in 115 hsecs
Run2 ran in 112 hsecs
run 1 ran in 102.68% of the time
......
LATCH.session switching 7 0 -7
LATCH.transaction branch alloc 7 0 -7
LATCH.channel operations paren 1 9 8
LATCH.library cache pin 32 24 -8
LATCH.enqueue hash chains 16 3 -13
LATCH.object queue header heap 0 18 18
STAT...redo size 3,184 3,164 -20
LATCH.object queue header oper 3 24 21
LATCH.dml lock allocation 23 0 -23
LATCH.cache buffers chains 158 133 -25
LATCH.SQL memory manager worka 6 73 67
LATCH.checkpoint queue latch 0 171 171
LATCH.shared pool 1,008 7 -1,001
LATCH.library cache 4,073 2,061 -2,012

Run1 latches total versus runs -- difference and pct
Run1 Run2 Diff Pct
11,556 8,728 -2,828 132.40%

Tom Kyte
May 04, 2009 - 10:44 am UTC

they both used uga and pga memory - not sure what you mean by that.

As the linked to article states - the technique of

column = :bind

OR

(1=1 or :bind is null)


is superior to the context based approach for many reasons.

Is dynamic refcursor faster?

A reader, May 04, 2009 - 5:07 pm UTC

Excellent! So it seems in last few days you have seen a lot of related questions and no wonder this is one of the most eye catching thread! Please ignore the uga, pga stuff as it popped out once while constructing this test case and has disappeared ever since.
In our project we have several ref cursors based on input parameters passed to Java app server. From the example I have put above in question, do you agree that we should consider having dynamic sql for ref cursors instead of static sql even when static sql is possible?? Dynamic sql in ref cursor is clearly using softer soft parse which static sql is having no clue of. All my tests show that dynamic sql in ref cursors is significantly reducing latching when session cached cursor is used and even when cursor hit is not there the latching is less compared to static sql based ref cursors. This will help us migrating to RAC and in improving performance in general.
Thanks a lot!!

Tom Kyte
May 04, 2009 - 5:47 pm UTC

... From the example I have put above in question, do you agree
that we should consider having dynamic sql for ref cursors instead of static
sql even when static sql is possible?? ...

absolutely NOT

first of all - all sql is dynamic, 100% of sql in Oracle is dynamic sql - even static sql is dynamic.

static sql is a PROGRAMMING LANGUAGE thing. Static sql means the sql is known at compile time. The programming environment can do many things therefore - like validate the sql, check permissions (make sure it can run at runtime without error!), set up dependencies.

You use 'dynamic sql' IF AND ONLY IF your back is to the wall and you are FORCED to. It is the LAST PATH you want to take.


... Dynamic sql in ref cursor is clearly
using softer soft parse which static sql is having no clue of. ...

why do you say that??!?!?!?!?!? That is utterly false.

Is dynamic refcursor faster?

ora dev, May 04, 2009 - 6:46 pm UTC

"why do you say that??!?!?!?!?!? That is utterly false. "

I am saying that based on this example sent in the above question. Copying it below. The latches are fewer when using dynamic sql, even when session_cached_cursors = 0. When session_cached_cursors is enabled, the dynamic sql is having 100% hit whereas the static sql is not having(in bold below). I could be missing something(and honestly need your knowledgeable opinion) , but I am saying this based on running such test cases.

I am aware of your opinion on dynamic vs static sql, however, am surprised by the test results as given below.

SQL> create or replace procedure stat_refcursor1
2 as
3 type ref_cur is ref cursor;
4 cur_ref ref_cur;
5 vn_sal pls_integer := 1100;
6 vd_hiredate date := TO_DATE ('1/1/1982','MM/DD/YYYY');
7 BEGIN
8 for i in 1..1000
9 loop
10 open cur_ref for
11 SELECT * FROM EMP WHERE SAL > vn_sal AND HIREDATE < vd_hiredate;
12 close cur_ref;
13 end loop;
14 END;
15 /

Procedure created.

SQL>
SQL> create or replace procedure dyn_refcursor_1
2 as
3 type ref_cur is ref cursor;
4 cur_ref ref_cur;
5 vn_sal pls_integer := 1100;
6 vd_hiredate date := TO_DATE ('01-jan-1982','dd-mon-yyyy');
7 BEGIN
8 for i in 1..1000
9 loop
10 open cur_ref for
11 'SELECT * FROM EMP WHERE SAL > :vn_sal AND HIREDATE < :vd_hiredate'
12 USING vn_sal,vd_hiredate;
13 close cur_ref;
14 end loop;
15 END;
16 /

Procedure created.

SQL>
SQL> exec runStats_pkg.rs_start;

PL/SQL procedure successfully completed.

SQL> exec stat_refcursor1;

PL/SQL procedure successfully completed.

SQL> exec runStats_pkg.rs_middle;

PL/SQL procedure successfully completed.

SQL> exec dyn_refcursor_1;

PL/SQL procedure successfully completed.

SQL> exec runStats_pkg.rs_stop;


Run1 ran in 79 hsecs
Run2 ran in 76 hsecs
run 1 ran in 103.95% of the time
......
LATCH.object queue header oper 12 0 -12
LATCH.object queue header heap 12 0 -12
LATCH.JS queue state obj latch 36 0 -36
LATCH.checkpoint queue latch 48 96 48
LATCH.cache buffers chains 186 135 -51
LATCH.enqueue hash chains 77 19 -58
LATCH.SQL memory manager worka 6 73 67
STAT...undo change vector size 2,260 2,332 72
LATCH.enqueues 76 2 -74
STAT...redo size 3,040 3,124 84
LATCH.shared pool 1,002 2 -1,000
STAT...session cursor cache hi 4 1,004 1,000
LATCH.library cache 4,041 47 -3,994
LATCH.library cache lock 4,008 6 -4,002

Run1 latches total versus runs -- difference and pct
Run1 Run2 Diff Pct
11,736 2,579 -9,157 455.06%

And if softer soft parses are disabled then also dynamic refcursor is having far less latches.

SQL> alter session set session_cached_cursors = 0;

Session altered.

SQL> exec runStats_pkg.rs_start;

PL/SQL procedure successfully completed.

SQL> exec stat_refcursor1;

PL/SQL procedure successfully completed.

SQL> exec runStats_pkg.rs_middle;

PL/SQL procedure successfully completed.

SQL> exec dyn_refcursor_1;

PL/SQL procedure successfully completed.

SQL> exec runStats_pkg.rs_stop;




Run1 ran in 115 hsecs
Run2 ran in 112 hsecs
run 1 ran in 102.68% of the time
......
LATCH.session switching 7 0 -7
LATCH.transaction branch alloc 7 0 -7
LATCH.channel operations paren 1 9 8
LATCH.library cache pin 32 24 -8
LATCH.enqueue hash chains 16 3 -13
LATCH.object queue header heap 0 18 18
STAT...redo size 3,184 3,164 -20
LATCH.object queue header oper 3 24 21
LATCH.dml lock allocation 23 0 -23
LATCH.cache buffers chains 158 133 -25
LATCH.SQL memory manager worka 6 73 67
LATCH.checkpoint queue latch 0 171 171
LATCH.shared pool 1,008 7 -1,001
LATCH.library cache 4,073 2,061 -2,012

Run1 latches total versus runs -- difference and pct
Run1 Run2 Diff Pct
11,556 8,728 -2,828 132.40%



Tom Kyte
May 09, 2009 - 9:42 am UTC

all sql - repeat - all sql is dynamic sql - 100% of sql is dynamic sql in Oracle, static sql is a trick put forth by programming environments - at run time, they execute it dymamically

that said - the static sql trick is a very very good trick - in plsql - always use static sql whenever possible. The compile time checks - all 100% good, the dependencies setup - all 100% good.

but it is still dynamic sql.



In any case - you did notice and point out that session cached cursors was the culprit, you hit a performance regression bug in plsql present in 10g - not in 9i and fixed in 11g with available patches for 10g (reference bug 6510615 fixed)

ops$tkyte%ORA11GR1> create or replace procedure stat_refcursor1
  2  as
  3    type ref_cur is ref cursor;
  4    cur_ref    ref_cur;
  5    vn_sal    pls_integer := 1100;
  6    vd_hiredate date := TO_DATE ('1/1/1982','MM/DD/YYYY');
  7   BEGIN
  8      open cur_ref for
  9        SELECT * FROM EMP WHERE SAL > vn_sal AND HIREDATE < vd_hiredate;
 10      close cur_ref;
 11   END;
 12  /

Procedure created.

ops$tkyte%ORA11GR1> create or replace procedure dyn_refcursor_1
  2  as
  3    type ref_cur is ref cursor;
  4    cur_ref    ref_cur;
  5    vn_sal    pls_integer := 1100;
  6    vd_hiredate date := TO_DATE ('01-jan-1982','dd-mon-yyyy');
  7   BEGIN
  8      open cur_ref for
  9        'SELECT * FROM EMP WHERE SAL > :vn_sal AND HIREDATE < :vd_hiredate'
 10        USING vn_sal,vd_hiredate;
 11      close cur_ref;
 12   END;
 13  /

Procedure created.

ops$tkyte%ORA11GR1> exec runStats_pkg.rs_start;

PL/SQL procedure successfully completed.

ops$tkyte%ORA11GR1> exec for i in 1 .. 1000 loop stat_refcursor1; end loop;

PL/SQL procedure successfully completed.

ops$tkyte%ORA11GR1> exec runStats_pkg.rs_middle;

PL/SQL procedure successfully completed.

ops$tkyte%ORA11GR1> exec for i in 1 .. 1000 loop dyn_refcursor_1; end loop;

PL/SQL procedure successfully completed.

ops$tkyte%ORA11GR1> exec runStats_pkg.rs_stop(800);
Run1 ran in 10 cpu hsecs
Run2 ran in 9 cpu hsecs
run 1 ran in 111.11% of the time

Name                                  Run1        Run2        Diff

Run1 latches total versus runs -- difference and pct
Run1        Run2        Diff       Pct
1,355       1,385          30     97.83%

PL/SQL procedure successfully completed.




In 10g, you can see the root cause, the session cached cursor hits:

ops$tkyte%ORA10GR2> exec runStats_pkg.rs_stop(800);
Run1 ran in 13 cpu hsecs
Run2 ran in 11 cpu hsecs
run 1 ran in 118.18% of the time

Name                                  Run1        Run2        Diff
STAT...session cursor cache hi          14       1,008         994
LATCH.shared pool                    1,280         258      -1,022
LATCH.shared pool simulator          2,107          80      -2,027
LATCH.library cache lock             4,175         137      -4,038
LATCH.library cache                  4,416         377      -4,039
STAT...physical read total byt       8,192           0      -8,192
STAT...physical read bytes           8,192           0      -8,192
STAT...session uga memory max      249,588      65,464    -184,124
STAT...session pga memory max      196,608           0    -196,608
STAT...session pga memory         -589,824      65,536     655,360

Run1 latches total versus runs -- difference and pct
Run1        Run2        Diff       Pct
13,363       1,564     -11,799    854.41%

PL/SQL procedure successfully completed.



In 9i, you see it revert back:

run 1 ran in 100% of the time

Name                                  Run1        Run2        Diff
LATCH.shared pool                    3,106       2,109        -997
LATCH.library cache pin              4,077       6,081       2,004
LATCH.library cache                  7,183       9,200       2,017

Run1 latches total versus runs -- difference and pct
Run1        Run2        Diff       Pct
18,562      21,685       3,123     85.60%

PL/SQL procedure successfully completed.






Now that said - if you have the ability to use STATIC SQL - do so, it is good - there is nothing 'better' about using 'dynamic' sql when you could have used static.


Is dynamic cursor faster?

ora_dev, May 11, 2009 - 9:51 pm UTC

This surely helps. In 10g it definitely seemed surprising, erroneous. Now as you pointed out there is a patch available then I will try to get that(test again!!) instead of having a workaround with dynamic code. Thank you for this wonderful site.

Approach for variable select lists etc.

Michael, June 03, 2009 - 5:02 am UTC

Hi Tom,

i just read your article in Oracle Magazine "On Popularity and Natural Selection".

One remark: Another interesting advantage of our (see my review from November 30, 2004) is that you can bind non scalar variables, e.g.:

if p_dname is not null then
  l_query := l_query || 
             'and e.dname in ' ||
             ' (select column_value ' || 
               'from  table(cast(:dname as varchar2table))) ';
else
  l_query := l_query || 
             'and (:dname is null or 1=1) ';             
end if;


In our production code we are using this approach withoput any problems and the performance is optimal!

Additionally, in our environment we also have to deal with:

* variable select list,
* variable where conditions, and
* variable order-by clause.

Here's our approach to solve these dynamic-SQL requirements (without using DBMS_SQL):
First, variable does not mean that "anything goes".
Rather it means here that the available expressions in each clause have to be known at implementation time. The used combination of these available expressions at runtime is variable.
I have found that for about 99% of the dynamic-SQL use cases i've seen this is sufficient.

Please consider this package:

The specification:

create or replace package emp_query_pkg
is 
  type select_spec_t is record(
    e_empno    boolean not null := false,
    e_ename    boolean not null := false,
    e_sal      boolean not null := false,
    e_comm     boolean not null := false,
    e_effsal   boolean not null := false,
    e_deptno   boolean not null := false,
    d_deptno   boolean not null := false,
    d_dname    boolean not null := false,
    d_loc      boolean not null := false,
    d_nicename boolean not null := false
  );
 
  type where_spec_t is record(
    e_ename    emp.ename%type,
    e_minsal   emp.sal%type,
    e_maxsal   emp.sal%type,
    e_hireyear emp.hiredate%type,
    d_dname    dept.dname%type
  );
 
  subtype order_position_t is pls_integer range 1 .. 2;
  subtype order_sequence_t is pls_integer range 0 .. 1;
  subtype order_null_t     is pls_integer range 0 .. 1;
 
  order_desc        constant order_sequence_t := 0;
  order_asc         constant order_sequence_t := 1;
  order_nulls_first constant order_null_t := 0;
  order_nulls_last  constant order_null_t := 1;
 
  type order_column_t is record(
    position order_position_t,
    sequence order_sequence_t,
    nulls    order_null_t
  );
  type order_spec_t is record(
    e_ename  order_column_t,
    d_dname  order_column_t
  );
 
  type result_t is record(
    e_empno    emp.empno%type,
    e_ename    emp.ename%type,
    e_sal      emp.sal%type,
    e_comm     emp.comm%type,
    e_effsal   number,
    d_deptno   dept.deptno%type,
    d_dname    dept.dname%type,
    d_loc      dept.loc%type,
    d_nicename varchar2(32 char)
  ); 
  type result_tt is table of result_t index by pls_integer;
  type result_va is varray(100) of result_t;
 
  function open_query(p_select in select_spec_t,
                      p_where  in where_spec_t := null,
                      p_order  in order_spec_t := null,
                      p_rows   in positive     := null)
    return sys_refcursor; 
end emp_query_pkg;
/


The Body:

create or replace package body emp_query_pkg
is
  subtype max_varchar2_t      is varchar2(32767 byte);
  subtype column_expression_t is varchar2(100 char);
  subtype column_alias_t      is varchar2(30 byte);
 
  number_null constant column_expression_t := 'to_number(null)';
  char_null   constant column_expression_t := 'to_char(null)';
  date_null   constant column_expression_t := 'to_date(null)';
 
  type column_spec_t is record(
    col_expr  column_expression_t,
    col_null  column_expression_t,
    col_alias column_alias_t
  );
 
  e_empno    column_spec_t;
  e_ename    column_spec_t;
  e_hireyear column_spec_t;
  e_sal      column_spec_t; 
  e_comm     column_spec_t;
  e_effsal   column_spec_t;
  e_deptno   column_spec_t;
  d_deptno   column_spec_t;
  d_dname    column_spec_t;
  d_loc      column_spec_t;
  d_nicename column_spec_t;
 
  function column_spec(p_col_expr in column_expression_t,
                       p_col_null in column_expression_t,
                       p_col_alias in column_alias_t)
    return column_spec_t
  is
    l_column_spec column_spec_t;
  begin
    l_column_spec.col_expr := p_col_expr;
    l_column_spec.col_null := p_col_null;
    l_column_spec.col_alias := p_col_alias;
    return l_column_spec;
  end column_spec;
 
  procedure initialization
  is
  begin
    e_empno := column_spec('e.empno', number_null, 'e_empno');
    e_ename := column_spec('e.ename', char_null, 'e_ename');
    e_hireyear := column_spec('trunc(e.hiredate, ''YYYY'')', date_null, 'e_hireyear');
    e_sal := column_spec('e.sal', number_null, 'e_sal');
    e_comm := column_spec('e.comm', number_null, 'e_comm');
    e_effsal := column_spec('e.sal + nvl(e.comm, 0)', number_null, 'e_effsal');
    e_deptno := column_spec('e.deptno', number_null, 'e_deptno');
    d_deptno := column_spec('d.deptno', number_null, 'd_deptno');
    d_dname := column_spec('d.dname', char_null, 'd_dname');
    d_loc := column_spec('d.loc', char_null, 'd_loc');
    d_nicename := column_spec('d.dname || ''(in '' || d.loc || '')''', char_null, 'd_nicename');
  end initialization;

  procedure build_select(p_spec in select_spec_t, p_text out varchar2)   
  is
    l_as        constant max_varchar2_t := ' as ';
    l_separator constant max_varchar2_t := ', ';
    function build_column(p_flag in boolean, p_col_spec in column_spec_t)
      return varchar2
    is
    begin
      return case p_flag
               when true then p_col_spec.col_expr
               else p_col_spec.col_null
             end || l_as || p_col_spec.col_alias;
    end build_column;
  begin 
    p_text := 'select ' ||
              build_column(p_spec.e_empno, e_empno) ||  l_separator ||
              build_column(p_spec.e_ename, e_ename) ||  l_separator ||     
              build_column(p_spec.e_sal, e_sal) ||  l_separator ||     
              build_column(p_spec.e_comm, e_comm) ||  l_separator ||     
              build_column(p_spec.e_effsal, e_effsal) ||  l_separator ||     
              build_column(p_spec.e_deptno, e_deptno) ||  l_separator ||     
              build_column(p_spec.d_dname, d_dname) ||  l_separator ||     
              build_column(p_spec.d_loc, d_loc) ||  l_separator ||
              build_column(p_spec.d_nicename, d_nicename) ||  ' ';
  end build_select;
 
  procedure build_from_join(p_select in select_spec_t, p_order in order_spec_t,
                            p_from out varchar2, p_where out varchar2)
  is
  begin
    p_where := 'where 1=1 ';
    p_from := 'from emp e';
    if p_select.d_deptno or p_select.d_dname or p_select.d_loc or
       p_select.d_nicename or p_order.d_dname.position between 1 and 2
    then     
      p_from := p_from || ', dept d';
      p_where := p_where || 'and ' || e_deptno.col_expr || ' = ' ||
                 d_deptno.col_null || ' ';
    end if;
    p_from := p_from || ' ';
  end build_from_join;

  procedure build_where(p_spec in where_spec_t, p_text in out varchar2)
  is
  begin
    if p_spec.e_ename is not null
    then
      p_text := p_text || 'and ' || e_ename.col_expr || ' = :e_ename ';
    else
      p_text := p_text || 'and ((1=1) or (:e_ename is null)) ';
    end if;
    if p_spec.e_minsal is not null
    then
      p_text := p_text || 'and ' || e_sal.col_expr || ' >= :e_minsal ';
    else
      p_text := p_text || 'and ((1=1) or (:e_minsal is null)) ';
    end if;
    if p_spec.e_maxsal is not null
    then
      p_text := p_text || 'and ' || e_sal.col_expr || ' >= :e_maxsal ';
    else
      p_text := p_text || 'and ((1=1) or (:e_maxsal is null)) ';
    end if;
    if p_spec.e_hireyear is not null
    then
      p_text := p_text || 'and ' || e_hireyear.col_expr || ' = trunc(:e_hireyear, ''YYYY'') ';   
    else
      p_text := p_text || 'and ((1=1) or (:e_hireyear is null)) ';   
    end if;   
  end build_where;
 
  procedure build_order(p_spec in order_spec_t, p_text out varchar2)
  is
    l_separator constant max_varchar2_t := ', ';   
    function build_sequence(p_order_column in order_column_t)
      return varchar2
    is
    begin
      return case p_order_column.sequence
               when order_asc then 'asc'
               when order_desc then 'desc'                    
             end ||
             case p_order_column.nulls
               when order_nulls_first then ' nulls first'
               when order_nulls_last then ' nulls last'         
             end;
    end build_sequence;
  begin
    p_text := 'order by null';
    for l_i in 1 .. 2
    loop
      if p_spec.e_ename.position = l_i
      then
        p_text := p_text || l_separator || e_ename.col_expr || ' ' ||
                  build_sequence(p_spec.e_ename);
      end if;
      if p_spec.d_dname.position = l_i
      then
        p_text := p_text || l_separator || d_dname.col_expr || ' ' ||
                  build_sequence(p_spec.d_dname);
      end if;   
    end loop;
  end build_order;
 
  procedure build_query(p_select in max_varchar2_t, p_from in max_varchar2_t,
                        p_where in max_varchar2_t, p_order in max_varchar2_t,
                        p_max_rows in positive, p_text out max_varchar2_t)
  is
  begin
    p_text := 'select * from (' ||
              p_select || p_from || p_where || p_order ||
              ') where ' ||
              case
                when p_max_rows is not null then 'rownum <= :max_rows'
                else '((1=1) or (:max_rows is null))'
              end;
  end;                       
 
  function open_query(p_select in select_spec_t,
                      p_where  in where_spec_t := null,
                      p_order  in order_spec_t := null,
                      p_rows   in positive     := null)
    return sys_refcursor
  is
    l_select max_varchar2_t;
    l_from   max_varchar2_t;
    l_where  max_varchar2_t;
    l_order  max_varchar2_t;
    l_query  max_varchar2_t;
    l_cursor sys_refcursor;
  begin
    build_select(p_spec => p_select, p_text => l_select);
    build_from_join(p_select => p_select, p_order => p_order,
                    p_from => l_from, p_where => l_where);                    
    build_where(p_spec => p_where, p_text => l_where);
    build_order(p_spec => p_order, p_text => l_order);    
    build_query(p_select => l_select, p_from => l_from, p_where => l_where,
                p_order => l_order, p_max_rows => p_rows, p_text => l_query);   
    open l_cursor for l_query
      using p_where.e_ename, p_where.e_minsal, p_where.e_maxsal,
            p_where.e_hireyear, p_rows;
    return l_cursor;
  end open_query;
 
begin
  initialization;
end emp_query_pkg;
/


I hope the logic (and power) of this package (and its implementation) is quite obvious:
We can select the following columns/expressions:

* e.empno,
* e.ename,
* e.sal,
* e.comm,
* e.effsal (a calculated expression),
* e.deptno,
* d.deptno,
* d.dname,
* d.loc,
* d.nicename (a char expression).

It possible to filter by:

* ename,
* minimum salary,
* maximum salary,
* hireyear.

Finally the result set can be ordered by:

* ename,
* dname.

Here's a demo code that uses this package:

declare
  l_cursor sys_refcursor;
  l_select emp_query_pkg.select_spec_t;
  l_where  emp_query_pkg.where_spec_t;
  l_order  emp_query_pkg.order_spec_t;
  l_result emp_query_pkg.result_va;
begin
  l_select.e_ename := true;
  l_select.e_sal := true;
  l_where.e_minsal := 200;
  l_where.e_hireyear := trunc(to_date('1981', 'YYYY'), 'YYYY');
  l_order.e_ename.position := 1;
  l_order.e_ename.sequence := emp_query_pkg.order_desc;
  l_cursor := emp_query_pkg.open_query(l_select, l_where, l_order);
  fetch l_cursor bulk collect into l_result;
  for l_i in nvl(l_result.first, 0) .. nvl(l_result.last, -1)
  loop
    dbms_output.put_line(l_result(l_i).e_ename || '-' || l_result(l_i).e_sal); 
  end loop;
  close l_cursor;
end;
/


There are - in my opinion - three interesting things to point out (well, beside not using DBMS_SQL):

* To get the result set structure fixed, we use dummy columns with null values, if the corresponding column (or better expressions) are not selected. That not a lot of work for the SQL engine - of course there a litte bit of overhead, but i found that this overhead is minimal.
* The where clause is built so that the using clause can be fixed.
* The biggest advantage, i think: The interface of the package to the "user" is highly declarative. There are no strings that are passed around etc. Most of the dynamic SQL implementations i've seen were highly error prone and hard to debug, because they heavily relied on strings in the interface and tried to make simply everything possible.

Tom Kyte
June 03, 2009 - 12:13 pm UTC

Ok, this was way too long to read from start to finish

can you

a) distill down to the very essence what you are trying to convey
b) provide a much much much smaller example - a tiny - teeny tiny - one.


you did see the link way at the top of this page - they one that says "a superior way"

The very essence ...

Michael, June 04, 2009 - 4:25 am UTC

It's possible to use native dynamic SQL for variable select lists, too.
Most people use DBMS_SQL for this problem and they think that you cannot do it with NDS.
Well, i think that this is not really correct.
(Of course, variable means here that the available expressions in the select clause have to be known at implementation time. The used combination of these available expressions at runtime is variable.)

For variable where filters we need a fixed set of binds to be able to use NDS - for a variable select list we need a fix set of columns so that we can fetch into something fixed in PL/SQL.
So, we have to make sure that the number, datatypes and order of the columns is fixed.
We can achieve this if we return for example "dept.dname" when the dname column is required, otherwise we return the expression "to_char(null)".

With this trick we have always a result set with, for example, the following structure:
1. column: number(28), emp.empno / to_number(null)
2. column: varchar2(50), dept.dname / to_char(null)
3. column: date, emp.hiredate / to_date(null)
etc.

Of course, there is an overhead for the unnecessary dummy NULL columns - i found that this overhead is normally negligible.

Now, one might ask: "Why don't we simply return all columns with the real data, the user of the ref cursor can then throw away the unneed columns!?"
The answer is: "The existence or non-existence of a column in the select list (and therefore often the existence or non-existence of a table in the from clause!) can lead to dramatically different execution plans."
(My previous review include a - lengthy - code example implementing this approach.)
Tom Kyte
June 08, 2009 - 11:09 am UTC

... It's possible to use native dynamic SQL for variable select lists, too. ...

but, you do not have a variable select list then - you have a fixed select list. If you truly have a variable select list - you cannot use native dynamic sql in plsql.

If you do not have a variable select list (as you have, you do NOT have a variable select list) - then you should use native dynamic sql.


Take my "dump_csv" routine - try doing it without dbms_sql. You - in your api - can force the "thou shall have N columns of these specific types" - in general, for a utility function that takes a query as input and expects plsql to process it - you have to use dbms_sql.

Variable or not ...

A reader, June 09, 2009 - 10:20 am UTC

Hi Tom,

of course you're right, that we cannot use NDS if we have to work with simply "a query", i.e. some string containing some arbitrary query, like you have to in your "dump_csv" routine.

So, if you prefer to use the term "variable" only in this sense - that fine for me.
Then, "variable" means that we know virtually nothing about the query at design/compile time (and therefore we cannot use NDS).

But, doesn't follow then that we should NOT use the term "variable" for the above approach for the where clause ("X = :x_filter" / "(1=1 or :x_filter is null)")?

To use this approach we have to know at design time at least:

- The number of binds
- The exact filter criteria for each bind (equal/less/greater etc.)

Now, it's quite similar:
To use the suggestion for handling "different combinations" (but not completely arbitrary) of expressions in the select list, we have to know at design time:

- The number and contents of the expressions that should be available in the select list.

So, i think that our suggestion for the select clause is as variable or fixed (whatever you like to call it) as the approach for the where clause.

I have found that for about 80% of the dynamic SQL use cases i've seen (especially search forms) a combination of the above where approach combined with the above select approach is sufficient and can be implemented very efficient with NDS.
Tom Kyte
June 09, 2009 - 10:41 am UTC

where do you see anyone saying "("X = :x_filter" / "(1=1 or :x_filter is null)")" is variable?


That technique explicitly removes the varying number of binds - it makes it so there are a fixed number of binds that are always supplied. The *old* way - using the application context - was working around supplying a varying number of binds. The other technique works around varying number of bind inputs by making them a FIXED number of inputs....


... So, i think that our suggestion for the select clause is as variable or fixed (whatever you like to call it) as the approach for the where clause. ...

I agree - however - I don't see the comparison - nor the need for a variable select list - you are selecting from EMP - you have access to all of the columns - I fail to see why you wouldn't just select them. The client can ignore them if they are not interested in them.



Why you wouldn't just select them ...

Michael, June 10, 2009 - 4:57 am UTC

... where do you see anyone saying "("X = :x_filter" / "(1=1 or :x_filter is null)")" is variable? ...

Agreed - just wanted to clarify this point.

... I fail to see why you wouldn't just select them. The client can ignore them if they are not interested in them ...

Yes - that's the point!
I'll try to explain, why this is in more complex cases not advisable.

Yes, we might ask: "Why don't we simply return all columns with the real data, the user of the ref cursor can then throw away the unneed columns!?"
The answer (backed by at least by my experience) is: "The existence or non-existence of a column in the select list and therefore the existence or non-existence of a table, that provides this particular column, in the from clause plus the appropriate join(s), can lead to dramatically different execution plans and response times."

In the simple case where all the available expressions are based on the data of a single table this is not very critical.

Now, consider a more complex case where the data of the available columns/expressions in the select list is based on 20 different tables (for example table_1 .. table_20). And table_1 is the master table, table_2 .. table_20 are the detail tables.
If we know that for a particular query only the data from table_1, table_4 and table_17 is required to provide the data for the expressions in the select list (or for the filters in the where clause), we can exclude table_2/3/5..16/18..20 completely from the query, i.e. we don't have to reference them in the from clause and therefore don't have to join them to the other tables.
select t1.AAA,
       to_number(null) BBB, /* could be t2.BBB */
       to_char(null) CCC, /* could be t3.CCC */
       t4.DDD,
       /* ... some to_XXX(null) expressions as placeholders 
          for the columns from table_5 .. table_16 ... */
       t17.KKK,
       /* ... again some to_XXX(null) expressions as placeholders 
          for the columns from table_18 .. table_20 ... */
from   table_1 t1,
       table_4 t4,
       table_17 t17
where  t1.id = t4.id_from_t1
and    t1.id = t17.id_from_t1
/* ... all the possible filters coded in the style 
   of the "X = :x_filter" / "(1=1 or :x_filter is null)" ...
*/    

If we don't use the to_XXX(null) dummy columns, we could:

- Leave the unneeded columns/expressions away in the select clause, but then we cannot do NDS because we have a changing select list (number of columns/datatypes),

or

- just select all the data from all tables and let the client ignore the unneeeded data. This works with NDS, but it's quite probable that we would experience sub-optimal performance - particularly when more tables are involved - mainly because of unnecessary joins. I found that in complex cases the difference in "consistent gets" between the "get all" and the "get only what's absolutely necessary otherwise to_XXX(null)" approaches can be noteworthy, ranging from factor 1 (of course) to 10.

Recursive Call while the Cursor is open

Parthiban Nagarajan, June 26, 2009 - 8:11 am UTC

Hi Tom ...

We cannot open a cursor (2nd time) when its already open; But I do that with "recursive" procedures ...
(1) It looks normal and very meaningful ... But "Why / How" its allowed ... ?

(2) And will those cursors remain opened until the recursive call finishes ... ?

-- Here is the code snippet ...

declare
summary number := 0;
procedure recursive_fun(p_number number)
is
cursor c_number(cp_number number) is
select cp_number from dual;
l_number number;
begin
open c_number(p_number);
fetch c_number into l_number;
if l_number != 0 then
summary := summary + l_number;
recursive_fun(l_number - 1);
end if;
close c_number;
end recursive_fun;
begin
recursive_fun(5);
dbms_output.put_line(summary);
end;
/

Tom Kyte
June 26, 2009 - 11:08 am UTC

yes, they have to be kept open - you haven't allowed them to close again

ops$tkyte%ORA10GR2> declare
  2    summary number := 0;
  3    procedure recursive_fun(p_number number)
  4    is
  5      cursor c_number(cp_number number) is
  6      select cp_number from dual;
  7      l_number number;
  8          l_n number;
  9    begin
 10      open c_number(p_number);
 11          select count(*) into l_n from v$open_cursor where sid = (select sid from v$mystat where rownum=1);
 12          dbms_output.put_line( 'there are now ' || l_n || ' open cursors' );
 13
 14      fetch c_number into l_number;
 15      if l_number != 0 then
 16        summary  := summary + l_number;
 17        recursive_fun(l_number - 1);
 18      end if;
 19      close c_number;
 20    end recursive_fun;
 21  begin
 22    recursive_fun(5);
 23    dbms_output.put_line(summary);
 24  end;
 25  /
there are now 15 open cursors
there are now 16 open cursors
there are now 17 open cursors
there are now 18 open cursors
there are now 19 open cursors
there are now 20 open cursors
15

PL/SQL procedure successfully completed.



the answer to "why/how" is the same answer as for a non-recursive environment - think of the "first call" - why or how are those cursors permitted?

They are allocated on the stack of the procedure, they are just local variables. Their scope is limited to the procedure itself, they come into existence when the procedure is called and go away when it returns.

The second invocation is conceptually no different than the first, you just have an entirely different set of local variables.

Display Hierarchy structure

Divya, August 12, 2009 - 2:36 am UTC

I have following table: -

Menu_ID
Menu_Name
Menu_parent_id
Menu_Type

This table stores the data in a tree structure as follows:-
1. First Level is the Parent Link. For parent link, menu_ID and Menu_parent_id will have the same value.
2. For Second level Menu_ID is picked up from a sequence and Menu_parent_id has the value of menu_ID of the first level.

This is the sample date: -

Menu_ID Menu_Name Menu_parent_id Menu_Type
2167 Parent_Link 2167 P
2168 SubLink1_Level1 2167 S
2169 SubLink2_Level1 2167 S
2170 SubLink1_1_Level2 2168 S
2171 SubLink2_1_Level2 2168 S
2172 SubLink3_1_Level2 2168 S
2173 SubLink1_2_Level2 2169 S
2174 SubLink2_2_Level2 2169 S
2175 Parent_Link_2 2175 P

We need to display the complete hierarchy structure using a stored procedure. We have achieved this using cursors for up to 8 levels (Loop under loop up to 8 levels). But the issue is that the number of levels can increase.
We need to display the hierarchy as: -
Parent Link 1
--Sublink1_Level1
--Sublink1_1_Level2
--Sublink1_1_1_Level3
--Sublink1_1_1_1_Level4
--Sublink2_Level2
Parent Link 2
Parent Link 3

Can this be done using ref cursors, by passing menu_id and menu_parent_id dynamically to the cursor? Can you suggest an efficient way to achieve this?

Thanks,
Divya

Tom Kyte
August 13, 2009 - 11:36 am UTC

no creates
no inserts
no sql generated by me for you

read about CONNECT BY, it can do this in a single sql statement.

Create, Insert and query used

Divya, August 14, 2009 - 4:55 am UTC

Thanks Tom.
Below is create and insert for the table:-

CREATE TABLE "CUSTOMER_MENU_TABLE"
("MENU_ID" NUMBER,
"MENU_NAME" VARCHAR2(4000 BYTE),
"MENU_PARENT_ID" NUMBER,
"MENU_TYPE" VARCHAR2(50 BYTE),
"CUSTOMER_ID" NUMBER
)

INSERT INTO CUSTOMER_MENU_TABLE VALUES (2167,'Parent_Link',2167,'P',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (2168,'SubLink1_Level1',2167,'S',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (2169,'SubLink2_Level1',2167,'S',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (2170,'SubLink1_1_Level2',2168,'S',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (2171,'SubLink2_1_Level2',2168,'S',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (2172,'SubLink3_1_Level2',2168,'S',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (2173,'SubLink1_2_Level2',2169,'S',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (2174,'SubLink2_2_Level2',2169,'S',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (2175,'Parent_Link_2',2175,'P',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (1123,'Parent_Link_3',2175,'P',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (1965,'Parent_Link_4',2175,'P',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (2179,'SubLink4_Level1,1965,'P',1);

I tried using connect by and have created the following SQL:

SELECT substr( rpad('*', 4*level, '*' ) || menu_name, 1, 500 ) menu_name, menu_id FROM customer_menu_table START WITH menu_id in (select menu_parent_id from customer_menu_table where menu_id=menu_parent_id and customer_id=1) CONNECT BY menu_parent_id = PRIOR menu_id and PRIOR menu_parent_id <> menu_id

I am seleting on the basis of customer_id as in original table there are multiple customer_ids.

This query is returing duplicated rows. Can you please help.

Thanks.
Divya.
Tom Kyte
August 24, 2009 - 7:43 am UTC

ops$tkyte%ORA10GR2> SELECT substr( rpad('*', 4*level, '*' ) || menu_name, 1, 500 ) menu_name, menu_id
  2    FROM customer_menu_table
  3   START WITH menu_id in (select menu_parent_id from customer_menu_table where menu_id=menu_parent_id and customer_id=1)
  4  CONNECT BY menu_parent_id = PRIOR menu_id and PRIOR menu_parent_id <> menu_id
  5  /

MENU_NAME                         MENU_ID
------------------------------ ----------
****Parent_Link                      2167
********SubLink1_Level1              2168
************SubLink1_1_Level2        2170
************SubLink2_1_Level2        2171
************SubLink3_1_Level2        2172
********SubLink2_Level1              2169
************SubLink1_2_Level2        2173
************SubLink2_2_Level2        2174
****Parent_Link_2                    2175
********Parent_Link_3                1123
********Parent_Link_4                1965
************SubLink4_Level1          2179

12 rows selected.



please define "duplicated rows" in this context? I don't see anything I'd consider "duplicated"?

Additional Information

Divya, August 14, 2009 - 5:31 am UTC

I have just noticed, that in my table there are cases where menu_id is same for two different customers. Hence i modified the query as follows

SELECT substr( rpad('*', 4*level, '*' ) || menu_name, 1, 500 ) menu_name, menu_id FROM customer_menu_table where customer_id=1 START WITH menu_id in (select menu_parent_id from customer_menu_table where menu_id=menu_parent_id and customer_id=1) CONNECT BY menu_parent_id = PRIOR menu_id and PRIOR menu_parent_id <> menu_id;

I have added a few more insert statement and corrected some of the earlier ones. Please use the following inserts:

INSERT INTO CUSTOMER_MENU_TABLE VALUES (2167,'Parent_Link',2167,'P',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (2168,'SubLink1_Level1',2167,'S',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (2169,'SubLink2_Level1',2167,'S',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (2170,'SubLink1_1_Level2',2168,'S',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (2171,'SubLink2_1_Level2',2168,'S',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (2172,'SubLink3_1_Level2',2168,'S',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (2173,'SubLink1_2_Level2',2169,'S',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (2174,'SubLink2_2_Level2',2169,'S',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (2175,'Parent_Link_2',2175,'P',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (1123,'Parent_Link_3',1123,'P',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (1965,'Parent_Link_4',1965,'P',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (2179,'SubLink4_Level1',1965,'P',1);
INSERT INTO CUSTOMER_MENU_TABLE VALUES (1965,'Parent_Link_1',1111,'S',2);

Thanks,
Divya.
Tom Kyte
August 24, 2009 - 7:44 am UTC

ops$tkyte%ORA10GR2> SELECT substr( rpad('*', 4*level, '*' ) || menu_name, 1, 500 ) menu_name, menu_id
  2    FROM customer_menu_table
  3   START WITH menu_id in (select menu_parent_id from customer_menu_table where menu_id=menu_parent_id and customer_id=1)
  4  CONNECT BY menu_parent_id = PRIOR menu_id and PRIOR menu_parent_id <> menu_id
  5  /

MENU_NAME                         MENU_ID
------------------------------ ----------
****Parent_Link_1                    1965
********Parent_Link_4                1965
************SubLink4_Level1          2179
********SubLink4_Level1              2179
****Parent_Link_3                    1123
****Parent_Link_4                    1965
********SubLink4_Level1              2179
****Parent_Link                      2167
********SubLink1_Level1              2168
************SubLink1_1_Level2        2170
************SubLink2_1_Level2        2171
************SubLink3_1_Level2        2172
********SubLink2_Level1              2169
************SubLink1_2_Level2        2173
************SubLink2_2_Level2        2174
****Parent_Link_2                    2175

16 rows selected.


I still see nothing I would call "duplicated"

Marked duplicate Values

Divya, August 25, 2009 - 2:55 am UTC

Hi Tom,

The descrepencies are as follows:-

1. Parent_Link_1 belongs to Customer_id 2 and should not appear in the link.

2. SubLink4_Level1 appears twice. Its Parent link is Parent_Link_4 and it should come in the result set only for that parent link. It seems to be returning for both Parent_Link_4 and Parent_Link_1 and it is also returning Parent_Link_4 twice in the result set: -

****Parent_Link_1 1965
********Parent_Link_4 1965
************SubLink4_Level1 2179
********SubLink4_Level1 2179

AND

****Parent_Link_4 1965
********SubLink4_Level1 2179

I solved the above by replacing the table customer_menu_table table with an inline view in the FROM clause. The query is as follows: -

SELECT substr( rpad('*', 4*level, '*' ) || menu_name, 1, 500 ) menu_name, menu_id
FROM
(select * from customer_menu_table where customer_id=1)
START WITH
menu_id in
(select menu_parent_id from
(select * from customer_menu_table where customer_id=1)
where menu_id=menu_parent_id )
CONNECT BY
menu_parent_id = PRIOR menu_id and PRIOR menu_parent_id <> menu_id;

Not sure if this is the best way, but this query does give me the result.

:)

Regards,
Divya

It is what i am looking for but,

Fowad, September 10, 2009 - 5:12 am UTC

I am really nervous by the "fair warning".
I am a junior level programmer and my administrator wants me to write a procedure to select dynamically from one or more tables, one or many or all columns and number of rows desired.

Upto my understanding i have to declare variables for tablenames, column_names and 'rownum'.

I've tried to use the sys_context but i donot understand it. I will how ever if i see it running correctly for once at my sqlplus window. 

version of database is 11g and we have just shifted from sql-server 2008  to oracle 11g. 

CREATE TABLE "FOWAD"."S_INFO" 
   ( "STUDENTID" NUMBER(14,0), 
 "STUDENT_NAME" VARCHAR2(30 BYTE), 
 "STUDENT_CLASS" VARCHAR2(30 BYTE), 
 "STUDENT_RECORD" VARCHAR2(200 BYTE)
   ) ;
 CREATE TABLE "FOWAD"."S_RECORD" 
   ( "STUDENTID" NUMBER(10,0), 
 "STUDENT_NAME" VARCHAR2(30 BYTE)
   ) 
REM INSERTING into S_RECORD
Insert into S_RECORD (STUDENTID,STUDENT_NAME) values (4,'ali');
Insert into S_RECORD (STUDENTID,STUDENT_NAME) values (3,'fowad');
Insert into S_RECORD (STUDENTID,STUDENT_NAME) values (2,'mehkaan');
Insert into S_RECORD (STUDENTID,STUDENT_NAME) values (1,'sajjad ');

REM INSERTING into S_INFO
Insert into S_INFO (STUDENTID,STUDENT_NAME,STUDENT_CLASS,STUDENT_RECORD) values (4,'ali','final year masters','C- through out');
Insert into S_INFO (STUDENTID,STUDENT_NAME,STUDENT_CLASS,STUDENT_RECORD) values (3,'fowad','1st year mba','A through out');
Insert into S_INFO (STUDENTID,STUDENT_NAME,STUDENT_CLASS,STUDENT_RECORD) values (2,'mehkaan','2nd year fsc','A++ through out');
Insert into S_INFO (STUDENTID,STUDENT_NAME,STUDENT_CLASS,STUDENT_RECORD) values (1,'sajjad','first year fsc','A+ through out');

create or replace context my_ctx USING my_procedure;
create or replace
   procedure my_procedure( p_col1   in varchar2 default NULL,
                           p_col2 in varchar2 default NULL,
                           p_col3       in varchar2 default NULL,
   p_col4 in varchar2 default NULL  
   )
    as
       type rc is REF CURSOR;
    
       l_cursor rc;
      l_query  varchar2(2000)
                default 'select a.studentid,a.student_name,b.student_class,b.student_record
from s_record a
full outer join s_info b on a.studentid=b.studentid ';
  
      cursor l_template is select s_record.studentid,s_record.student_name,student_class,student_record
 from s_record,s_info;
       l_rec  l_template%rowtype;
begin

      if ( p_col1 is NOT NULL ) then
          dbms_session.set_context( 'MY_CTX', 'STUDENTID', '%'||upper(p_col1)||'%');
          l_query := l_query ||'select sys_context( ''MY_CTX'', ''STUDENTID'' )
 from s_record ';
      end if;
If ( p_col2 is NOT NULL ) then
          dbms_session.set_context( 'MY_CTX', 'STUDENT_NAME',
                                    '%'||upper(p_col2)||'%');
          l_query := l_query ||'select sys_context( ''MY_CTX'', ''STUDENTID'' ),
sys_context( ''MY_CTX'', ''STUDENT_NAME'' )
 from s_record ';
      end if;
If ( p_col3 is NOT NULL ) then
          dbms_session.set_context( 'MY_CTX', 'B.STUDENT_CLASS',
                                    '%'||upper(p_col3)||'%');
          l_query := l_query ||'select sys_context( ''MY_CTX'', ''A.STUDENTID'' ),
sys_context( ''MY_CTX'', ''A.STUDENT_NAME'' ),sys_context( ''MY_CTX'', ''B.STUDENT_CLASS'' )
 from s_record a
full outer join s_info b on a.studentid=b.studentid' ;
      end if;
If ( p_col4 is NOT NULL ) then
          dbms_session.set_context( 'MY_CTX', 'B.STUDENT_RECORD',
                                    '%'||upper(p_col4)||'%');
          l_query := l_query ||'select sys_context( ''MY_CTX'', ''A.STUDENT_RECPRD'' ),
sys_context( ''MY_CTX'', ''A.STUDENT_NAME'' ),sys_context( ''MY_CTX'', ''B.STUDENT_CLASS'' ),
sys_context( ''MY_CTX'', ''B.STUDENT_CLASS'' )
 from s_record a
full outer join s_info b on a.studentid=b.studentid' ;
END IF;


open l_cursor for l_query;
      loop
          fetch l_cursor into l_rec;
          exit when l_cursor%notfound;
          dbms_output.put_line( L_REC.P_COL1 || ',' ||
                                l_rec.P_COL2 || ',' ||
                                l_rec.P_COL3 || ',' || 
    l_rec.P_COL4);
      end loop;
      close l_cursor;
  end;


SQL> show error
Errors for PROCEDURE MY_PROCEDURE:

LINE/COL ERROR
-------- -----------------------------------------------------------------
54/11    PL/SQL: Statement ignored
54/39    PLS-00302: component 'P_COL1' must be declared
SQL>
P_ROWSCOUNT NUMBER(1) :=0;

I do not know what i am doing , i am totally lost sir. 
My administrator have asked me ..' write me a procedure . it should prompt me for table names ( i skipped table name part in this procedure) . Also i should prompt me for column names of as many columns i want to view from tables OR if i pass through it ( NULL) it should give me All Columns of the tables. Also it should prompt me of how many records i want to see, i.e if i input 200, the procedure should return 200 rows ( ROWNUM). 

If this question is not absurd. Can i please have you point out my mistakes. 

 

Tom Kyte
September 14, 2009 - 11:10 am UTC

... I am really nervous by the "fair warning". ...

what would that be? I'm not sure what you are referring to - this page is HUGE.


... Upto my understanding i have to declare variables for tablenames, column_names
and 'rownum'.
...

you cannot bind identifiers, you cannot bind tablenames, you cannot bind column names and I don't know what it means to bind "rownum", you can bind an input to compare to rownum..


... I've tried to use the sys_context but i donot understand it. I will how ever if
i see it running correctly for once at my sqlplus window.
...

the problem is, I'm not sure what you are trying to do. Posting code that doesn't work doesn't describe the problem you are trying to solve?



... ' write me a procedure . it should prompt me
for table names ( i skipped table name part in this procedure) . Also i should
prompt me for column names of as many columns i want to view from tables OR if
i pass through it ( NULL) it should give me All Columns of the tables. Also it
should prompt me of how many records i want to see, i.e if i input 200, the
procedure should return 200 rows ( ROWNUM).
....


Ok, you don't tell me what language you are using, but here goes -

first - plsql won't prompt you for anything (like Tsql won't prompt you). It is a stored procedure, it accepts formal inputs and returns outputs.

Here is a procedure that returns to the client a result set of the first N rows it finds in a table, somewhat safely:

(two implementations, I prefer the former over the latter)

ops$tkyte%ORA11GR1> create or replace
  2  function foo
  3  ( p_tname in varchar2,
  4    p_nrows in number,
  5    p_cols  in sys.odcivarchar2list default null ) return sys_refcursor
  6  as
  7      l_sql    long := 'select ';
  8      l_cursor sys_refcursor;
  9  begin
 10      if ( p_cols is not null )
 11      then
 12          for i in 1 .. p_cols.count
 13          loop
 14              l_sql := l_sql || dbms_assert.simple_sql_name( p_cols(i) ) || ', ';
 15          end loop;
 16      else
 17          l_sql := l_sql || 't.*, ';
 18      end if;
 19
 20      l_sql := l_sql || 'rownum r from ' || dbms_assert.sql_object_name( p_tname ) || ' t where rownum <= :x';
 21
 22      open l_cursor for l_sql using p_nrows;
 23      return l_cursor;
 24  end;
 25  /

Function created.

ops$tkyte%ORA11GR1>
ops$tkyte%ORA11GR1> variable x refcursor
ops$tkyte%ORA11GR1> exec :x := foo( 'scott.emp', 4 )

PL/SQL procedure successfully completed.

ops$tkyte%ORA11GR1> print x

     EMPNO ENAME      JOB              MGR HIREDATE         SAL       COMM
---------- ---------- --------- ---------- --------- ---------- ----------
    DEPTNO          R
---------- ----------
      7369 SMITH      CLERK           7902 17-DEC-80        800
        20          1

      7499 ALLEN      SALESMAN        7698 20-FEB-81       1600        300
        30          2

      7521 WARD       SALESMAN        7698 22-FEB-81       1250        500
        30          3

      7566 JONES      MANAGER         7839 02-APR-81       2975
        20          4


ops$tkyte%ORA11GR1> exec :x := foo( 'scott.emp', 4, sys.odcivarchar2list( 'ename', 'empno', 'hiredate' ) )

PL/SQL procedure successfully completed.

ops$tkyte%ORA11GR1> print x

ENAME           EMPNO HIREDATE           R
---------- ---------- --------- ----------
SMITH            7369 17-DEC-80          1
ALLEN            7499 20-FEB-81          2
WARD             7521 22-FEB-81          3
JONES            7566 02-APR-81          4

ops$tkyte%ORA11GR1>
ops$tkyte%ORA11GR1> create or replace
  2  function foo
  3  ( p_tname in varchar2,
  4    p_nrows in number,
  5    p_cols  in varchar2 default null ) return sys_refcursor
  6  as
  7      l_sql    long := 'select ';
  8      l_cursor sys_refcursor;
  9      l_cols   dbms_utility.uncl_array;
 10      l_n      number;
 11  begin
 12      if ( p_cols is not null )
 13      then
 14          dbms_utility.comma_to_table( p_cols, l_n, l_cols );
 15          for i in 1 .. l_n
 16          loop
 17              l_sql := l_sql || dbms_assert.simple_sql_name( l_cols(i) ) || ', ';
 18          end loop;
 19      else
 20          l_sql := l_sql || 't.*, ';
 21      end if;
 22
 23      l_sql := l_sql || 'rownum r from ' || dbms_assert.sql_object_name( p_tname ) || ' t where rownum <= :x';
 24      dbms_output.put_line( l_sql );
 25
 26
 27      open l_cursor for l_sql using p_nrows;
 28      return l_cursor;
 29  end;
 30  /

Function created.

ops$tkyte%ORA11GR1> exec :x := foo( 'all_users', 3, 'username, created' );
select username,  created, rownum r from all_users t where rownum <= :x

PL/SQL procedure successfully completed.

ops$tkyte%ORA11GR1> print x

USERNAME                       CREATED            R
------------------------------ --------- ----------
SYS                            03-AUG-07          1
SYSTEM                         03-AUG-07          2
OUTLN                          03-AUG-07          3







modified.

Fowad, September 11, 2009 - 5:51 am UTC

I have been reading the entire thread and come up with this procedure, Kindly take a look upon it.

Today was the deadline for my work, At-least i am saved from getting fired.

CREATE OR REPLACE PROCEDURE ppwithrownum(col1 in varchar2 default null,
                                         col2 in varchar2 default null,
                                         col3 in varchar2 default null,
                                         col4 in varchar2 default null,
                                         rslt OUT sys_refcursor) AS
  str     VARCHAR2(1000);
  str_t   varchar2(100);
  str_t_2 varchar(200);
  str_w   varchar2(200);
BEGIN
  str_t   := ' from s_info';
  str_t_2 := 'from s_info a,s_info b';
  str_w   := 'where a.studentid=b.studentid';
  if col1 is not null and col2 is null and col3 is null and col4 is null then
    str := 'select' || ' ' || col1 || ' ' || str_t;
  else
    if col1 is not null and col2 is not null and col3 is null and
       col4 is null then
      str := 'select' || ' ' || col1 || ',' || col2 || ' ' || str_t;
    else
      if col1 is not null and col2 is not null and col3 is not null and
         col4 is null then
        str := 'select' || ' ' || 'A.' || col1 || ',' || 'A.' || col2 || ',' || 'B.' || col3 || ' ' ||
               str_t_2 || ' ' || str_w;
      else
        str := 'select' || ' ' || 'A.' || col1 || ',' || 'A.' || col2 || ',' || 'B.' || col3 || ',' || 'B.' || col4 || ' ' ||
               str_t_2 || ' ' || str_w;
      end if;
    end if;
  end if;
  OPEN rslt FOR str;
END;


1) I am not sure about the impact of continuous else if conditions in the code, as well as the <expressions> i.e col1 is not null and col2..................

2) This procedure is working for crystal reports but to test it i have to do this routine in Jdeveloper.

DECLARE
COL1 VARCHAR2(200);
COL2 VARCHAR2(200);
COL3 VARCHAR2(200);
COL4 VARCHAR2(200);
RSLT sys_refcursor;
BEGIN
COL1 := 'STUDENTID';
COL2 := NULL;
COL3 := NULL;
COL4 := NULL;

PP(
COL1 => COL1,
COL2 => COL2,
COL3 => COL3,
COL4 => COL4,
RSLT => RSLT
);
-- Modify the code to output the variable
-- DBMS_OUTPUT.PUT_LINE('RSLT = ' || RSLT);
END;

How do i see the results at sqlplus window

3) how do i modify it to take user prompts .

Sir , if i see your follow up i will be able to modify it accordingly


Tom Kyte
September 14, 2009 - 11:58 am UTC

erase this code, it is so subject to sql injection.



see above


and - plsql will not, cannot "prompt" you - an application would be necessary for that, but you still don't say what is calling this.


just like tsql, you do not write interactive applications in a STORED procedure.

Sorry for late reply

Fowad, September 30, 2009 - 12:27 am UTC

I am sorry for the late reply sir. My internet access was restricted as according to administration "i was spending too much time browsing database sites"
"Fair warning" are ...( FAIR WARNING
If your followup requires a response that might include a ...)


Your Function have helped me greatly. The packages you have used in function are what i have never even heard before.
i have erased the injection code but my supervisor was extremely happy with it :)

My coding language is Pl/sql. I use applications for coding: Plsql developer v7.1.2 and Jdeveloper of oracle 11g.

The calling application is Crystal Reports 2008 ( cr developer v12.0.0.63).
I have to create procedures in pl/sql and call them in crystal reports for reporting. This is what we were use to do in sql server ( t-sql ).

I have encountered this behavior that it runs cursors and sys.refcursor as in packages(containing procedures and functions) and only cursors in stand alone procedures.

I am going to modify below procedure as per your functions (foo)approach
CREATE OR REPLACE PROCEDURE print_from_table(table_name         IN VARCHAR2,
                                             table_column_value IN VARCHAR2) IS

  --Define local variables.
  l_query VARCHAR2(2000);

  -- Define a local function to ensure table does exist.
  FUNCTION verify_table(object_name_in IN VARCHAR2) RETURN BOOLEAN IS
  
    retval BOOLEAN := FALSE;
  
    CURSOR find_object IS
      SELECT null FROM user_objects WHERE object_name = object_name_in;
  BEGIN
    -- The for-loop sets the Boolean when a table is found
  
    FOR i IN find_object LOOP
      retval := TRUE;
    END LOOP;
    -- Return Boolean state.
    RETURN retval;
  END verify_table;
BEGIN
  -- If table exists insert into it.
  IF verify_table(table_name) = TRUE THEN
    -- Build dynamic SQL statement.
    l_query := 'select ' || table_column_value || ' ' || 'from ' ||
                 table_name;
  
    EXECUTE IMMEDIATE l_query;
  
  END IF;
END print_from_table
;

also my packages are some what like this so far.

create table ORDERS
(
ID NUMBER(10), --- primary key---
ORDERSTATUS NUMBER,
ORDERSTAGE NUMBER,
ORDERDATE DATE,
AGENTID NUMBER,
MANAGERID NUMBER,
VERIFIERID NUMBER,
CCVERIFIERID NUMBER,
DOP DATE,
STATUSDATE DATE
)
insert into ORDERS (ID, ORDERSTATUS, ORDERSTAGE, ORDERDATE, AGENTID, MANAGERID, VERIFIERID, CCVERIFIERID, DOP, STATUSDATE)
values (395, null, 7, to_date('02-07-2009 06:35:00', 'dd-mm-yyyy hh24:mi:ss'), 100, null, null, null, null, to_date('12-09-2009', 'dd-mm-yyyy'));
insert into ORDERS (ID, ORDERSTATUS, ORDERSTAGE, ORDERDATE, AGENTID, MANAGERID, VERIFIERID, CCVERIFIERID, DOP, STATUSDATE)
values (396, null, 1, to_date('02-07-2009 06:36:00', 'dd-mm-yyyy hh24:mi:ss'), 96, null, null, null, null, to_date('12-09-2009', 'dd-mm-yyyy'));
insert into ORDERS (ID, ORDERSTATUS, ORDERSTAGE, ORDERDATE, AGENTID, MANAGERID, VERIFIERID, CCVERIFIERID, DOP, STATUSDATE)
values (397, 2, 4, to_date('02-07-2009 06:37:00', 'dd-mm-yyyy hh24:mi:ss'), 138, 45, 19, null, null, to_date('12-09-2009', 'dd-mm-yyyy'));
insert into ORDERS (ID, ORDERSTATUS, ORDERSTAGE, ORDERDATE, AGENTID, MANAGERID, VERIFIERID, CCVERIFIERID, DOP, STATUSDATE)
values (398, null, 7, to_date('16-07-2009 06:38:00', 'dd-mm-yyyy hh24:mi:ss'), 79, null, null, null, null, to_date('26-09-2009', 'dd-mm-yyyy'));


CREATE OR REPLACE PACKAGE agent_report_withcte IS

 TYPE T_agent_C IS REF CURSOR;
 PROCEDURE GET_ctereport (r_agent OUT T_agent_C ,
  AGENTID VARCHAR2,
  STARTDATE VARCHAR2,
  ENDDATE VARCHAR2);

END agent_report_withcte;

CREATE OR REPLACE PACKAGE BODY agent_report_withcte IS

  PROCEDURE GET_ctereport(r_agent   OUT T_agent_C,
                          AGENTID   VARCHAR2,
                          STARTDATE VARCHAR2,
                          ENDDATE   VARCHAR2) AS
                          
  BEGIN
  
    OPEN r_agent FOR 
    WITH AGENT_SALES AS
    (
      SELECT agentid, orderstatus
        FROM orders
       WHERE agentid = nvl(agentid, agentid)
         AND orderdate BETWEEN nvl(startdate, orderdate) AND
             nvl(enddate, orderdate)
          OR dop between nvl(startdate, dop) AND nvl(enddate, dop)
          OR statusdate between nvl(startdate, statusdate) AND
             nvl(enddate, statusdate)
      
       )
        SELECT *
          FROM (SELECT AGENTID, orderstatus FROM orders) 
          PIVOT(COUNT(ORDERSTATUS) 
          FOR ORDERSTATUS IN (1 AS PAID, 2 AS PENDING, 3 AS REFUND, 4 AS CHARGEBACK, 5 AS DECLINED, 6 AS INVALID, 7 AS CANCEL, 8 AS HOLD, 9 AS STOLENCARD, 10 AS PICKUP, 11 AS VOID))
         ORDER BY AGENTID;
  
  END GET_ctereport;

END agent_report_withcte;


This is to show your kind sir my efforts so far.
Respect and Regards .
Fowad Syed
Tom Kyte
October 07, 2009 - 7:46 am UTC

  IF verify_table(table_name) = TRUE THEN
    -- Build dynamic SQL statement.
    l_query := 'select ' || table_column_value || ' ' || 'from ' ||
                 table_name;


umm, why bother verifying the table_name if you are just going to blindly use table_column_value.

and why not use dbms_assert??? why did you waste your time reinventing something that already exists? and was demonstrated to you on this page?


  IF verify_table(table_name) = TRUE THEN
    -- Build dynamic SQL statement.
    l_query := 'select ' || table_column_value || ' ' || 'from ' ||
                 table_name;
  
    EXECUTE IMMEDIATE l_query;
  
  END IF;
END print_from_table



that code makes no sense, you execute immediate a select - without an into, that does NOTHING. Not sure what you are attempting, but you did nothing in that entire procedure, nothing.



Feedback of using dynamic where criteria

Rajeswari, December 08, 2009 - 1:34 am UTC

I read your new approach. But similar solution is already given by Darko Egersdorfer from South Africa

if ( p_ename is NOT NULL ) then
l_query := l_query ||
' and ename like ''%''||:p_ename||''%''';
else
l_query := l_query ||
' and 1 = DECODE(:p_ename,NULL,1,1)';
end if;

We implemented above solution as we not able to get "create context" privilege.

Now you suggested to use OR instead of decode.

Many times you said in your forum "Test the solution even if it is given by expert"

Really it requires courage to publish the better solution self defeating initial solution. Thanks for your work Tom.
Tom Kyte
December 10, 2009 - 8:25 am UTC

yes, the decode is similar, but not identical

ops$tkyte%ORA10GR2> variable x varchar2(30)
ops$tkyte%ORA10GR2>
ops$tkyte%ORA10GR2> set autotrace traceonly explain
ops$tkyte%ORA10GR2> select * from dual where 1=decode(:x,null,1,1);

Execution Plan
----------------------------------------------------------
Plan hash value: 3752461848

---------------------------------------------------------------------------
| Id  | Operation          | Name | Rows  | Bytes | Cost (%CPU)| Time     |
---------------------------------------------------------------------------
|   0 | SELECT STATEMENT   |      |     1 |     2 |     2   (0)| 00:00:01 |
|*  1 |  FILTER            |      |       |       |            |          |
|   2 |   TABLE ACCESS FULL| DUAL |     1 |     2 |     2   (0)| 00:00:01 |
---------------------------------------------------------------------------

Predicate Information (identified by operation id):
---------------------------------------------------
<b>
   1 - filter(DECODE(:X,NULL,1,1)=1)
</b>
ops$tkyte%ORA10GR2> select * from dual where (1=1 or :x is null);

Execution Plan
----------------------------------------------------------
Plan hash value: 272002086

--------------------------------------------------------------------------
| Id  | Operation         | Name | Rows  | Bytes | Cost (%CPU)| Time     |
--------------------------------------------------------------------------
|   0 | SELECT STATEMENT  |      |     1 |     2 |     2   (0)| 00:00:01 |
|   1 |  TABLE ACCESS FULL| DUAL |     1 |     2 |     2   (0)| 00:00:01 |
--------------------------------------------------------------------------

ops$tkyte%ORA10GR2> set autotrace off



the predicate is not removed, the 'or' trick allowed the CBO to entirely remove the where clause at compile time.

open cursor for query using

Tunde, March 10, 2010 - 10:29 am UTC

Hello Tom,

I am writing a function for use of general reporting for different SQL statements used in our applications. (Oracle 10g R2)

Is it possible to use OPEN CURSOR FOR QUERY USING in a loop? where the variables are bind variables for the DML retrieved from a table.

v_query is a dynamic query that can have zero or more conditions to be met in the where clause.

for i in 1 .. p_arglist.count
       loop
                    
            OPEN c1 FOR v_query USING p_arglist(i);
                    
                 
       end loop;


I try running that and an error of not all bound variables comes on.

Many thanks for your anticipated advice and response.

Tom Kyte
March 10, 2010 - 10:37 am UTC

no, of course you cannot do that - think about it. when you loop the first time, you need to know all of the binds - else we cannot possibly open the statement - can we?

Retrieving DML from a table, a classic trademark of an application done wrong. sigh.....

You would need to either use dbms_sql for this (it can parse a statement AND THEN BIND one at a time AND THEN open the statement)

or

use the techniques outlined here:
https://www.oracle.com/technetwork/issue-archive/2009/09-jul/o49asktom-090487.html

if you want to use native dynamic sql

OR (my personal favorite)

revisit your design and use static sql, not sql stuffed into a table with inputs slid in from the side by magic. Generic is 'so cool', and so hard to maintain, to tune, to make perform, to secure, to understand, to implement with and so on.

Generic so cool?

Matt McPeak, March 10, 2010 - 3:57 pm UTC

You've often expressed your preference for "problem-specific" solutions over "generic" ones involving dynamic code (example: above). I completely agree and often refer to your postings when I am accused of "hardcoding my design" or "not building for the future".

But you last comment made me wonder -- how do you feel about most Java-based frameworks out there? So much of a Java application nowadays is stuffed into configuration files (usually XML) that have a HUGE impact on what the final application does. Isn't that another case of frameworks trying to be generic at the expense of maintenance and readability? Or, is there a difference in your view?

I know it's off topic: I'm sure you'll feel free to tell me to get lost ) Thanks!

Tom Kyte
March 11, 2010 - 8:13 am UTC

If you leave the java to the user interface and plsql to the data processing, the java stuff can do whatever it wants - I don't really care.

Because it is just lipstick at that point.

When the java is doing some real processing, then people like me are called in to look at the performance "problem" by the application developers themselves (which must be in the database - it is a database application after all) at which point we spend a lot of time proving "the time spent in the database is X, the time spent processing is Y, Y is much larger than X, X is just N% of Y (and N is a single digit), therefore, even if we made X go to zero (made the database infinitely fast) you would still have a long processing time. Therefore, guess where the efficiencies need to be made..."

Then we get lectured on sunk costs, "openness", portability, etc. But it doesn't matter - because again, even if the database was infinitely fast - they would not run that much faster...

what about all the parsing

russellh, March 11, 2010 - 7:01 pm UTC

"If you leave the java to the user interface and plsql to the data processing, the java stuff can do whatever it wants - I don't really care. "

But if you have an application that is very read heavy (like reading a bit of user profile information for every page hit), aren't you burdening the database with all that "soft parsing" if you use PL/SQL and refcursors? A lot of these modern frameworks support cursor caching, so why not enjoy the increased throughput of not needing to parse the same statement over and over? I think I remember that you were advocating this approach in your Effective Oracle by Design book. If an expert DBA reviews the java code, and understands how it interacts with the database do you think you can achieve a sound application design?
Tom Kyte
March 12, 2010 - 3:07 pm UTC

... But if you have an application that is very read heavy (like reading a bit of
user profile information for every page hit), aren't you burdening the database
with all that "soft parsing" if you use PL/SQL and refcursors? ...

why would I return a refcursor for a bit of structured information, you would use a refcursor if an only if you needed to return a glob of data, a result set. And most times - you do not.

... A lot of these
modern frameworks support cursor caching, so why not enjoy the increased
throughput of not needing to parse the same statement over and over? ...

because the flipside is the 'great' SQL generated by these frameworks. Somethings gotta give. I'll use refcursors before I want their SQL.


... If an expert DBA reviews the java code, and understands how it
interacts with the database do you think you can achieve a sound application
design? ...

show me the environment where that happens first.


This is like discussions I have about triggers, when others and autonomous transactions.... Do I fully well know they can be used for good? Yes, absolutely. Do I fully well know they are almost always abused? Used incorrectly? Yes, absolutely. So in the end, I choose the lesser of two evils - I would rather seem them disappear as features than allow them to remain.

re: Java frameworks vs. stored procedures

Stew Ashton, March 13, 2010 - 7:04 am UTC


I detest frameworks such as Hibernate because they are not tools: they aim to replace people, not empower them. Anyway, you don't need frameworks to get statement caches, you just need a JDBC driver or a J2EE Server that provides connection pooling and prepared statement caches.

Resistance to stored procedures and promotion of frameworks are both signs of the same fundamental evil : the desire to ignore the database and treat it as a black box.

Forcing people to write in PL/SQL will stop them from using SQL generators, but it will not keep them from writing bad code. I saw a stored procedure using dynamic SQL without bind variables less than a week ago.

Worse, management may say "all right, everyone use stored procedures" and next thing you know we'll have a TAPI generator that's just as bad as a java framework, or maybe both together!

It all starts and ends with people using their heads and wanting to learn and do things right.
Tom Kyte
March 15, 2010 - 9:55 am UTC

It all starts and ends with people using their heads and wanting to learn and do things right.

well said.

How to fetch latest records from cursor

prathyu, September 29, 2010 - 1:06 pm UTC

Hi Tom,

My requirement is as follows

1)Fetching records into cursor(C_TEMP) from table TEMP (assume 10 rows are there)

2)Opend the cursor (C_TEMP) in loop, based on some condition in side of the loop inserting few records into same TEMP table(assume 2 new records are inserted after 4th and 6th iteration). Now I want to continue the same loop till 12th record (10 existing + 2 newly inserted in side of the above loop)

is there any possibility?

Thanks in advance and sorry for my english...
Tom Kyte
September 29, 2010 - 1:23 pm UTC

there is no possibility - no. The result set identified by your cursor is as of the point in time it was opened - there is no chance to see anything added after it was opened.

Using ref cursor in other SQL

djb, November 04, 2010 - 8:49 am UTC

Tom,

I've been looking through the docs and can't find an example so I'm wondering if it's even possible: can we use a ref cursor as input for another sql statement? Something like:

select ... from t where my_column in (ref_cursor)

I've had a couple of scenarios where that would be most helpful.
Tom Kyte
November 05, 2010 - 4:59 am UTC

No, it is not currently possible as of 11g Release 2.

You would have to wrap the ref cursor in a pipelined function that fetched and returned the data - then you would reference the pipelined function in a table clause in the query.

Mutex pin in Oracle 10g - Please help me to understand.

Rajeshwaran, Jeyabal, December 15, 2010 - 11:51 am UTC

Tom:

we have a packaged procedure developed for our application like this. And its been there from some 5 years back.


procedure  prc_process(p_key in number,p_sts out number)
as
 variable x refcursor;
begin
 open x for 
 select * from t_process
 where key = p_key;
 loop
  .......... application Buisness rules ............
  .......... goes here ..........
 end loop; 
 commit;
 close X;
exception
  when others then
   if x%isopen then
    close x;
   end if;
  raise_application_error (-20458,sqlerrm); 
end;
/


we will be Invoking this procedure from different session with different values passed for p_key parameter.
And it worked fine for some many years. From Yesterday night we had an issue with processing this procedure from different session.
The problem is Session-1 is working fine and the same procedure from Session-2 is getting blocked at this CURSOR.

We are hearing that Mutex pins wait events in database is causing this issues.

We are in Oracle 10.2.0.2.0 on Solaris. We dont have any Bitmap index in application database and NO SELECT for UPDATE statement in this procedure.

Questions
1) What is this Mutex pins about? the table t_process is list partitioned on the column key. I dont know how to reproduce this issue with some demo tables / datas
Tom Kyte
December 16, 2010 - 2:05 am UTC

if this is happening as you describe, you'll need to work with support. The mutex is a serialization device - probably in this case being used by the parse of the ref cursor.

Any reason you are using a ref cursor here and not just a normal cursor? It would cut down on the parsing. The snippet of code doesn't show the need for a ref cursor - is there one?

Mutex pin in Oracle 10g - Please help me to understand

Rajeshwaran, Jeyabal, December 16, 2010 - 6:54 am UTC

Tom:

Did benchmark in the same server using Ref-cursor and normal cursor and Tkprof shows me.

Using Refcursor

SELECT *
FROM
T_PROCESS RCUR WHERE KEY = :B1


call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        5      0.00       0.00          0          0          0           0
Execute      5      0.06       0.35          0          1          0           0
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total       10      0.06       0.36          0          1          0           0

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 100     (recursive depth: 1)


Normal cursor

SELECT * 
FROM
 T_PROCESS CUR WHERE KEY = :B1


call     count       cpu    elapsed       disk      query    current        rows
------- ------  -------- ---------- ---------- ---------- ----------  ----------
Parse        1      0.00       0.00          0          0          0           0
Execute      5      0.01       0.26          0          1          0           0
Fetch        0      0.00       0.00          0          0          0           0
------- ------  -------- ---------- ---------- ---------- ----------  ----------
total        6      0.01       0.26          0          1          0           0

Misses in library cache during parse: 1
Optimizer mode: ALL_ROWS
Parsing user id: 100     (recursive depth: 1)


Refcursors parsed once for each execution while normal cursor parsed only once for overall executions.

Questions
1) Do you think due to this Over-parsing of refcursor's the Session-2 is got hold by mutex pins?
Tom Kyte
December 16, 2010 - 7:07 am UTC

a ref cursor is always parsed with each and every OPEN call - they are never cached.

static cursors in plsql on the other hand are cached open after they are closed - plsql does this transparently and automatically. If you do not NEED a ref cursor (eg: you are NOT returning the cursor to a client, you are NOT doing dynamic sql) - you should not use one.


1) yes, that would be my theory based on the sparse information I have.

cursor

A reader, July 19, 2011 - 11:04 pm UTC


SQL causing Performance Issue

Sathish Akkala, August 04, 2011 - 1:45 am UTC

We have observed in few sqls that ":1 is coming prior to FROM condition with blank" why it is and what is the result of this query?
This query is fetching 11 K records. so utlimately CPU is going + 90%

Problamatic SQL:

SELECT
T4.CONFLICT_ID,
T4.LAST_UPD,
T4.CREATED,
T4.LAST_UPD_BY,
T4.CREATED_BY,
T4.MODIFICATION_NUM,
T4.ROW_ID,
T27.PR_RESP_ID,
T27.BU_ID,
T23.STATUS,
T27.PR_ALT_PH_NUM_ID,
T27.PR_EMAIL_ADDR_ID,
T16.SHARE_HOME_PH_FLG,
T27.PR_SYNC_USER_ID,
T10.OPTY_ID,
T27.PROVIDER_FLG,
T11.NAME,
T27.CURR_PRI_LST_ID,
T12.KEY_VALUE,
T27.CITIZENSHIP_CD,
T27.DEDUP_KEY_UPD_DT,
T18.ROW_ID,
T25.STATE,
T25.ADDR,
T25.COUNTRY,
T25.CITY,
T25.ZIPCODE,
T27.CUST_SINCE_DT,
T27.PR_REGION_ID,
T27.NATIONALITY,
T27.PR_SECURITY_ID,
T3.NAME,
T27.MED_SPEC_ID,
T14.PR_EMP_ID,
T27.PR_OU_ADDR_ID,
T24.PR_EMP_ID,
T17.LOGIN,
T14.PR_EMP_ID,
T27.PR_PROD_LN_ID,
T27.PR_TERR_ID,
T7.PR_SMS_NUM_ID,
T27.PR_STATE_LIC_ID,
T27.AGENT_FLG,
T27.MEMBER_FLG,
T27.PR_NOTE_ID,
T27.PR_INDUST_ID,
T21.LOGIN,
T7.PR_FAX_NUM_ID,
T27.SUPPRESS_MAIL_FLG,
T27.EMAIL_ADDR,
T27.JOB_TITLE,
T27.MID_NAME,
T27.PR_DEPT_OU_ID,
T27.LAST_NAME,
T27.SEX_MF,
T27.PR_PER_ADDR_ID,
T27.PR_POSTN_ID,
T23.PR_ADDR_ID,
T27.HOME_PH_NUM,
T27.OWNER_PER_ID,
T27.WORK_PH_NUM,
T27.FAX_PH_NUM,
T27.FST_NAME,
T13.ATTRIB_07,
T1.INTEGRATION_ID,
T27.PR_PER_PAY_PRFL_ID,
T27.PRIV_FLG,
T27.PR_MKT_SEG_ID,
T27.PR_REP_SYS_FLG,
T27.PR_REP_MANL_FLG,
T27.PR_REP_DNRM_FLG,
T27.PR_OPTY_ID,
T27.PR_GRP_OU_ID,
T27.EMP_FLG,
T5.OWN_INST_ID,
T5.INTEGRATION_ID,
T27.PERSON_UID,
T4.NAME,
T1.NAME,
T1.PRTNR_FLG,
T19.LOGIN,
T22.ROW_STATUS,
T2.ROW_ID,
T26.PRIM_MARKET_CD,
T2.ROW_ID,
T8.OU_NUM,
T8.LOC,
T8.NAME,
T2.ROW_ID,
T8.PR_SRV_AGREE_ID,
T8.PR_BL_PER_ID,
T8.PR_SHIP_PER_ID,
T8.PR_BL_ADDR_ID,
T8.PR_SHIP_ADDR_ID,
T6.LOGIN,
T27.ROW_ID,
T27.PAR_ROW_ID,
T27.MODIFICATION_NUM,
T27.CREATED_BY,
T27.LAST_UPD_BY,
T27.CREATED,
T27.LAST_UPD,
T27.CONFLICT_ID,
T27.PAR_ROW_ID,
T13.ROW_ID,
T13.PAR_ROW_ID,
T13.MODIFICATION_NUM,
T13.CREATED_BY,
T13.LAST_UPD_BY,
T13.CREATED,
T13.LAST_UPD,
T13.CONFLICT_ID,
T13.PAR_ROW_ID,
T16.ROW_ID,
T16.PAR_ROW_ID,
T16.MODIFICATION_NUM,
T16.CREATED_BY,
T16.LAST_UPD_BY,
T16.CREATED,
T16.LAST_UPD,
T16.CONFLICT_ID,
T16.PAR_ROW_ID,
T7.ROW_ID,
T7.PAR_ROW_ID,
T7.MODIFICATION_NUM,
T7.CREATED_BY,
T7.LAST_UPD_BY,
T7.CREATED,
T7.LAST_UPD,
T7.CONFLICT_ID,
T7.PAR_ROW_ID,
T5.ROW_ID,
T5.PAR_ROW_ID,
T5.MODIFICATION_NUM,
T5.CREATED_BY,
T5.LAST_UPD_BY,
T5.CREATED,
T5.LAST_UPD,
T5.CONFLICT_ID,
T5.PAR_ROW_ID,
T22.ROW_ID,
T20.ROW_ID,
T2.ROW_ID,
T15.ROW_ID,
T10.ROW_ID,
T10.MODIFICATION_NUM,
T10.CREATED_BY,
T10.LAST_UPD_BY,
T10.CREATED,
T10.LAST_UPD,
T10.CONFLICT_ID,
T10.OPTY_ID,
T10.PER_ID,
T10.PER_ID,
T10.OPTY_ID,
:1
FROM
SIEBEL.S_ORG_EXT T1,
SIEBEL.S_PARTY T2,
SIEBEL.S_MED_SPEC T3,
SIEBEL.S_PARTY T4,
SIEBEL.S_CONTACT_SS T5,
SIEBEL.S_USER T6,
SIEBEL.S_CONTACT_LOYX T7,
SIEBEL.S_ORG_EXT T8,
SIEBEL.S_POSTN T9,
SIEBEL.S_OPTY_CON T10,
SIEBEL.S_PRI_LST T11,
SIEBEL.S_DQ_CON_KEY T12,
SIEBEL.S_CONTACT_X T13,
SIEBEL.S_POSTN T14,
SIEBEL.S_PARTY T15,
SIEBEL.S_EMP_PER T16,
SIEBEL.S_USER T17,
SIEBEL.S_CASE T18,
SIEBEL.S_USER T19,
SIEBEL.S_PARTY T20,
SIEBEL.S_USER T21,
SIEBEL.S_POSTN_CON T22,
SIEBEL.S_POSTN_CON T23,
SIEBEL.S_POSTN T24,
SIEBEL.S_ADDR_PER T25,
SIEBEL.S_ORG_EXT_FNX T26,
SIEBEL.S_CONTACT T27
WHERE
T14.PR_EMP_ID = T21.PAR_ROW_ID (+) AND
T1.PR_POSTN_ID = T24.PAR_ROW_ID (+) AND
T27.PR_POSTN_ID = T14.PAR_ROW_ID (+) AND
T27.PR_DEPT_OU_ID = T1.PAR_ROW_ID (+) AND
T4.ROW_ID = T23.CON_ID (+) AND T23.POSTN_ID (+) = :2 AND
T24.PR_EMP_ID = T17.PAR_ROW_ID (+) AND
T27.PR_PER_ADDR_ID = T25.ROW_ID (+) AND
T4.ROW_ID = T18.PR_SUBJECT_ID (+) AND
T27.MED_SPEC_ID = T3.ROW_ID (+) AND
T27.CURR_PRI_LST_ID = T11.ROW_ID (+) AND
T4.ROW_ID = T12.CONTACT_ID (+) AND
T4.ROW_ID = T27.PAR_ROW_ID AND
T4.ROW_ID = T13.PAR_ROW_ID (+) AND
T4.ROW_ID = T16.PAR_ROW_ID (+) AND
T4.ROW_ID = T7.PAR_ROW_ID (+) AND
T4.ROW_ID = T5.PAR_ROW_ID (+) AND
T27.PR_POSTN_ID = T22.POSTN_ID AND T27.ROW_ID = T22.CON_ID AND
T22.POSTN_ID = T20.ROW_ID AND
T22.POSTN_ID = T9.PAR_ROW_ID (+) AND
T9.PR_EMP_ID = T19.PAR_ROW_ID (+) AND
T27.PR_DEPT_OU_ID = T2.ROW_ID (+) AND
T27.PR_DEPT_OU_ID = T8.PAR_ROW_ID (+) AND
T27.PR_DEPT_OU_ID = T26.PAR_ROW_ID (+) AND
T27.PR_SYNC_USER_ID = T15.ROW_ID (+) AND
T27.PR_SYNC_USER_ID = T6.PAR_ROW_ID (+) AND T10.PER_ID = T4.ROW_ID AND
(T27.PRIV_FLG = 'N' AND T4.PARTY_TYPE_CD != 'Suspect') AND
(T10.OPTY_ID = :3)
ORDER BY
T27.PRIV_FLG, T27.LAST_NAME, T27.FST_NAME

Tom Kyte
August 04, 2011 - 10:22 am UTC

the :1 has nothing to do with it. It is just a bind variable constant they are selecting out.

ops$tkyte%ORA11GR2> variable bv1 varchar2(20)
ops$tkyte%ORA11GR2> variable bv2 varchar2(20)
ops$tkyte%ORA11GR2> 


ops$tkyte%ORA11GR2> exec :bv1 := 'Hello world'; :bv2 := 'X'

PL/SQL procedure successfully completed.

ops$tkyte%ORA11GR2> select dummy, :bv1 from dual where dummy = :bv2;

D :BV1
- --------------------------------
X Hello world

1 row selected.



It (that :1) is not likely to be affecting the performance of this query at all.

how to reduce over cursor execution time.

Ranjan, February 27, 2013 - 5:36 am UTC

Hi Tom,

Oracle version 10.2.0.1

I have created a table as below and inserted records upto 2.5 lakhs(some kb records).
##################
create table crores_2andhalf(a number,b number);

insert into crores_2andhalf select level,level+10 from dual connect by 2000001;
...
...
...
insert into crores_2andhalf select level+24000000,level+24000010 from dual connect by level<1000001;
###################

declare
var1 number;
l_start number default dbms_utility.get_time;

cursor cur1 is select a from crores_2andhalf
where a=5000000 or a=10000000 or
a=15000000 or a=20000000 or
a=25000000;
begin

for i in cur1
loop
dbms_output.put_line
('the derived value of a is : '||i.a||' '||
round((dbms_utility.get_time-l_start)/100, 2) ||
' Seconds...' );
l_start:=dbms_utility.get_time;

end loop;
end;
/
#########
the derived value of a is : 5000000 .95 Seconds...
the derived value of a is : 10000000 1.22 Seconds...
the derived value of a is : 15000000 .94 Seconds...
the derived value of a is : 20000000 1 Seconds...
the derived value of a is : 25000000 1.09 Seconds...

I am getting these output in sqldeveloper.

I used to get correct output of get_time or cpu_time in sql*plus(might be in 10.2.0.2)
but when I tried now to see the result from sql*plus I got below result(manytimes run but no change).

the derived value of a is : 5000000 10.27 Seconds...
the derived value of a is : 10000000 0 Seconds...
the derived value of a is : 15000000 0 Seconds...
the derived value of a is : 20000000 0 Seconds...
the derived value of a is : 25000000 0 Seconds...

so it is not changing get_time which is giving 0 seconds results.

I thought may be I need to change default date and timestamps format for the session(even I know that
will not affect get_time function).
I changed date format to : DD-MON-RR HH24.mi.ss
timestamp to:DD-MON-RR HH.MI.SSXFF AM
timestamp zone to:DD-MON-RR HH.MI.SSXFF AM TZR
but no luck same "zero seconds..".

Is it a sql*plus bug or I need to set something.

This was my secondary doubt(regarding sql*plus).

But My primary requirment ( I have tried to do and failed every time :( ).


suppose we know
we are fetching 50 records (from that cursor),
and each fetch might take around 2 minutes.
As you told some other page its like page/file(that cursor thing how,
for normal query select * from
big_table; it does not take much time ,fraction of time actually
for single fetch, I liked that concept:)).

In my senario there is a process(may be so transformation or may be simple sqlquery) which takes arround 1 minute in every fetch.
so overhaul time for that job which is taking =2*50+1*50=150 minutes.

But I am thinking to reduce that fetch wait time for the next fetch and so on(what I mean
without waiting for the process to complete how to start second fetch simultaneously).
so in that way the overhaul time for that job would be around=2*50=100 minutes.
(1*50 for processes will be run along with fetch).

I tried with pipelined function but I think it couldnt be done with that.
I even thought of "using some buffer technique to store the next fetches
while it is processing process for first fetch" but which is not possible as the next fetch starts
after first fetch and all related process in that loop.

could you please give some idea how to accomplish this(process and fetch simultaneously).

Hope I explained the issue properly.

thanks as always,
Ranjan.








Tom Kyte
February 27, 2013 - 8:09 am UTC

You used to get the "right" answer (both answers are right by the way...) in 9i and before. When you upgraded to 10g - you started getting this "new" "but also correct" answer.


In 10g and above, a process that performs:


for x in CURSOR
loop
   ....


for x in (select .... )
loop
   ...




will implicitly array fetch 100 rows at a time, meaning when you go for the first row, you'll actually be retrieving the first 100 rows into your application - plsql will cache the 99 rows for you while you process the first row. When you ask for row 2, you'll get it straight away.

This is done for performance and scalability - it is a very very desirable feature. It is called bulk processing, array fetching.


To defeat it - to go back to slow by slow processing, to undo the goodness it does, you may either:


a) compile with optimization level set to 1, the default is 2.

b) use an explicit cursor:

declare
   c cursor is select ....;
   l_rec c%rowtype;
begin
   open c;
   loop
       fetch c into l_rec;
       exit when c%notfound;
       .... process l_rec here ...
   end loop;
   close c;
end;


but I do not suggest doing this.

thanks Tom.

Ranjan, February 27, 2013 - 2:12 pm UTC

thank you very much for the answer.


I knew bulkprocessing and arrayfetching ,but not deeply like you explained.

I knew like unless until those 100 fetch completed we cant process anything(very bad concept ha ha).
you are always there for us to guide in right path.
God bless you.


I checked that sqlplus thing and able to produce it, as you said :)

Thanks Tom.

sorry ,I have missed something to ask

Ranjan, February 27, 2013 - 4:06 pm UTC

Hi Tom,
You told after 10g upgrade it is showing correct answer.
Is it like select systimestamp from big_table;
through out the result systimestamp is same.
I mean to say like that they have maintained that time as same through out fetches. I am not sure but I guess.

Could you please tell the actual reason behind to maintain get_time
like that in 10g.

regards,
Ranjan

sorry ,I have missed something to ask

Ranjan, February 27, 2013 - 4:07 pm UTC

Hi Tom,
You told after 10g upgrade it is showing correct answer.
Is it like select systimestamp from big_table;
through out the result systimestamp is same.
I mean to say like that they have maintained that time as same through out fetches. I am not sure but I guess.

Could you please tell the actual reason behind to maintain get_time
like that in 10g.

regards,
Ranjan

sqldeveloper actually confused me

Ranjan, February 27, 2013 - 10:56 pm UTC

you have clearly mentioned
for var in cur1 loop
....

or for var in (select ..) loop
implicitely bulk process happens.
that I got it.(so in my query it is obvious to get as result zero seconds in 10 g and above ,which i got in above posted testcases).

But my only confusion is , in my office yesterday the version is 10.2.0.1 from sqlplus i got correct answer like
zero second from second fetch.

But how come in sqldeveloper i got those result differs from
sqlplus every times I ran(database is same data is same).
I will send the version of sqldeveloper.

I found many times sqldeveloper behaves strangely(commits take 6 to 7 seconds).

thanks,
many things to learn from you.



all my mistakes.

Ranjan, February 28, 2013 - 1:04 am UTC

Hi Tom,

I found that sqldeveloper which I am having at office has
a plsql_optimize_level=0 by default ,so that is causing the issue.
I changed to 2 and everything is ok.

now I am very happy ,learnt new thing from you.

Heart felt thank you to YOU.

cursor

A reader, May 23, 2013 - 4:35 am UTC


To find maximum concurrent session counts on daily basis

Suresh R, August 20, 2013 - 10:06 am UTC

Hi Tom,

Thanks for your support.
Am facing unique constraint violated issue when tried executing below code.
My requirement is to collect day,unique user count, session count and maximum concurrent session count per day from one table and insert the values into another table on daily basis.

Example:
-----------
Below is my two tables definition and count.

desc PCM_SESSION_SUMMARY
Name       Null     Type         
---------- -------- ------------ 
SESS_ID    NOT NULL NUMBER       
USER_CUPID          VARCHAR2(10) 
START_TS            TIMESTAMP(6) 
END_TS              TIMESTAMP(6) 
ACT_CNT             NUMBER       

desc pcm_session_summary_daily
Name                    Null     Type   
----------------------- -------- ------ 
SESS_DT                 NOT NULL DATE   
UNIQUE_USER_CNT                  NUMBER 
SESS_CNT                         NUMBER 
MAX_CONCURRENT_SESS_CNT          NUMBER 

SQL> select count(*) from PCM_SESSION_SUMMARY;

  COUNT(*)
----------
      1725

SQL> select count(*) from pcm_session_summary_daily;

  COUNT(*)
----------
         0

SQL>

So i should read from PCM_SESSION_SUMMARY and insert into pcm_session_summary_daily table. I wrote below code but am facing issue with below error.

ERROR at line 1:
ORA-00001: unique constraint (G3COST.SYS_C00687927) violated
ORA-06512: at "G3COST.TEST_19AUG13_2", line 27
ORA-06512: at line 1

To find maximum concurrent session counts on daily basis

Suresh R, August 20, 2013 - 10:10 am UTC

This is my code.

create or replace 
procedure test_19aug13_2
is
cursor summ_1 is
select trunc(start_ts,'DDD') start_ts,count(distinct(user_cupid)) user_cnt,count(SESS_ID) Sess_cnt
from PCM_SESSION_SUMMARY
where START_TS < sysdate or START_TS > (select max(sess_dt) from TEST_SESS_SUMM_DAILY where sess_dt < sysdate)
group by trunc(start_ts,'DDD')
order by start_ts;
summ_rec1 summ_1%rowtype;
cursor summ_2 is
select distinct trunc(start_ts,'hh24') as start_dt,
trunc(end_ts,'hh24') as end_dt,trunc(start_ts,'DDD') start_t,count(SESS_ID) sess_cn
from PCM_SESSION_SUMMARY
where trunc(start_ts,'ddd')= summ_rec1.start_ts
group by trunc(start_ts,'hh24'),trunc(end_ts,'hh24'),trunc(start_ts,'DDD')
order by 1;
summ_rec2 summ_2%rowtype;
begin
open summ_1;
loop
fetch summ_1 into summ_rec1;
exit when summ_1%NOTFOUND;
open summ_2;
loop
fetch summ_2 into summ_rec2;
exit when summ_2%NOTFOUND;
insert into TEST_SESS_SUMM_DAILY values (summ_rec1.start_ts,summ_rec1.user_cnt,summ_rec1.Sess_cnt,summ_rec2.sess_cn);
end loop;
close summ_2;
end loop;
commit;
close summ_1;
end test_19aug13_2;
/

It is created successfully without an error and getting error when executing. Kindly let me know if am wrong any where.

Below is my db details..
SQL> select name,open_mode from v$database;

NAME      OPEN_MODE
--------- ----------
Z1XX      READ WRITE

SQL> select version from v$instance;

VERSION
-----------------
11.1.0.7.0

Kate, October 26, 2016 - 7:59 am UTC


trigger not work

khaled zerimeche, August 04, 2019 - 2:32 pm UTC

Hi team,

I want to create a trigger PL/SQL for the table: ap_supplier_sites_all (oracle EBS R12), in this table i have below information: vendor_site_id (primary key), vendor_id, attribute4 (varchar250), my trigger will be developp for avoid the insert or update the attribute4 if this attribute4 exists in the table for each vendor_id,



i do two triggers:



1first trigger:



CREATE OR REPLACE TRIGGER TRIG

BEFORE INSERT OR UPDATE of attribute4 ON ap_supplier_sites_all

referencing new as new old as old

for each row

BEGIN

IF :new.attribute4 in (123,789,78965,12345) -- (select distinct attribute4 from ap_supplier_sites_all) --(123,789,78965,12345) trigger and vendor_id not in

THEN

RAISE_APPLICATION_ERROR(-20101, 'This RIB exists with another Suppliers.Please try with a new RIB');

ROLLBACK;

END IF;

END ;



i have two issues for this trigger:

1. i cant compare the : :new.attribute4 for the selection in the table (select distinct attribute4 from ap_supplier_sites_all)

2. this trigger check the attribute4 for each vendor_site_id not for the vendor_id, beacause the vendor_site_id is the primary key.





2 second trigger:



CREATE OR REPLACE TRIGGER TRIGg

BEFORE insert or update ON ap_supplier_sites_all

referencing new as new old as old

for each row

DECLARE

v_vendor_id ap_supplier_sites_all.vendor_id%TYPE;

v_attribute4 ap_supplier_sites_all.attribute4%TYPE;



CURSOR cur IS

SELECT distinct ap_supplier_sites_all.attribute4,ap_supplier_sites_all.vendor_id

from ap_supplier_sites_all;

BEGIN

open cur;

--for attribute4 in (SELECT distinct ap_supplier_sites_all.attribute4 from ap_supplier_sites_all)

LOOP

FETCH cur INTO v_attribute4,v_vendor_id;

EXIT WHEN cur%NOTFOUND;

IF :new.attribute4=v_attribute4

THEN

RAISE_APPLICATION_ERROR(-20101, 'This RIB exists with another Suppliers.Please try with a new RIB');

END IF;

END LOOP;

CLOSE cur;

END;



when i do this trigger, i have the issue from oracle application:



Error while saving Saving :Vendor Site Name azertyyyiii: Vendor site id :844562. Error :ORA-20001: APP-SQLAP-10000: ORA-04091: table AP.AP_SUPPLIER_SITES_ALL is mutating, trigger/function may not see it ORA-06512: at "APPS.TRIGG", line 6 ORA-06512: at "APPS.TRIGG", line 9 ORA-04088: error during execution of trigger 'APPS.TRIG in Package AP_VENDOR_PUB_PKG Procedure Update_Vendor_Site

please help me it very emergency.
Connor McDonald
August 05, 2019 - 9:19 am UTC

This is not related in any way to the question

sai, August 16, 2022 - 10:48 am UTC

hi Tom can u do this please
Create a Cursor to list the Students Who have secured More than 90% in a particular grade
Connor McDonald
August 17, 2022 - 4:07 am UTC

open rc for
select *
from students
where grade > 90



is my best guess without any other information to go on

More to Explore

PL/SQL demos

Check out more PL/SQL tutorials on our LiveSQL tool.

PL/SQL docs

PL/SQL reference manual from the Oracle documentation library