Skip to Main Content
  • Questions
  • Identify when a function is executed in a SQL Query or in a PL/SQL procedure

Breadcrumb

Question and Answer

Chris Saxon

Thanks for the question, Konstantinos.

Asked: February 07, 2019 - 9:00 am UTC

Last updated: February 08, 2019 - 1:58 pm UTC

Version: Oracle Database 12c Enterprise Edition Release 12.1.0.2.0

Viewed 1000+ times

You Asked

Is there any way to identify when a pl/sql function is executed in SQL Query and when is executed in a procedure or PL/SQL anonymous block? (I don't want to pass any parameter for manual identification)

The main reason I need that is when a function is executed in a SQL query I wouldn't like to raise an exception in case of failure, I would be satisfied just with a returned value NULL. But the same function when is executed in pl/sql script I want to raise exception.

Thank you in advance.

and Chris said...

You mean from within a function detect whether it was called by SQL or PL/SQL?

I don't think there's a reliable method available. You'll run into complications if you have a complex call stack with multiple levels of PL/SQL & SQL.

But there is a hack available.

The exception NO_DATA_FOUND isn't propagated when you call PL/SQL in SQL. So you can use this to "return null" instead of get an exception when calling it from SQL:

create or replace function f 
  return int as
begin

  raise no_data_found;
  
  return 1;
  
end f;
/

select f from dual;

F        
  <null> 

declare
  v integer;
begin
  v := f;
end;
/

Error report -
ORA-01403: no data found

Rating

  (2 ratings)

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

Comments

why, oh why?

Racer I., February 08, 2019 - 9:10 am UTC

Hi,

Mmmh. This smacks of the dreaded WHEN OTHERS THEN NULL paradigm.
If NULL is good enough for SQL why not for PL/SQL too?
Then you could :
begin
  v := f;
  IF (v IS NULL) THEN
     RAISE ...;
  END IF;
end;

Although this looses the real reason.
Or wrap the function in another one for in-SQL-use (like you would also do to map boolean to Y/N or 1/0).
The hack doesn't seem to cover the anonymous block requirement.
Ultimately one would need more info on the real problem this is meant to address.

regards,
Chris Saxon
February 08, 2019 - 11:07 am UTC

The hack doesn't seem to cover the anonymous block requirement.

Not sure what you're saying there - calling the function in an anonymous block raises NDF, which meets the requirement, no?

Ultimately one would need more info on the real problem this is meant to address.

Indeed. This requirement is a little... unusual. There's probably a better way to achieve this.

mumble

Racer I., February 08, 2019 - 12:26 pm UTC

Hi,

> The hack doesn't seem to cover the anonymous block requirement.

My bad. I tend to group anonymous PL/SQL more with SQL than with packaged PL/SQL. Should have reread that part.

re(ar)gards,
Chris Saxon
February 08, 2019 - 1:58 pm UTC

No worries :)

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