Thread: no_data_found oracle vs pg
Hello everyone, On Oracle, a no_data_found exception is raised from pl/sql but not from sql (it returns null). It's well known. Connected to: Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production SQL> create or replace function hello return char is 2 c char; 3 begin 4 select 'a' into c from dual where 1=2; 5 return c; 6 end; 7 / Function created. SQL> select coalesce(hello(),'<NULL>') from dual; COALESCE(HELLO(),'<NULL>') -------------------------------------------------------------------------------- <NULL> SQL> declare 2 res char; 3 begin 4 res:=hello(); 5 end; 6 / declare * ERROR at line 1: ORA-01403: no data found ORA-06512: at "JM.HELLO", line 4 ORA-06512: at line 4 On PG, with the strict keyword, we get: psql (15.2) Type "help" for help. JM=> create or replace function hello_strict() returns char language plpgsql as $function$ JM$> declare JM$> c char; JM$> begin JM$> select 'a' into strict c where 1=2; JM$> return c; JM$> end;$function$; CREATE FUNCTION JM=> select coalesce(hello_strict(),'<NULL>'); ERROR: query returned no rows CONTEXT: PL/pgSQL function hello_strict() line 5 at SQL statement JM=> do $$declare JM$> res char; JM$> begin JM$> res:=hello_strict(); JM$> end$$; ERROR: query returned no rows CONTEXT: PL/pgSQL function hello_strict() line 5 at SQL statement PL/pgSQL function inline_code_block line 4 at assignment And without the strict keyword: JM=> create or replace function hello_not_strict() returns char language plpgsql as $function$ JM$> declare JM$> c char; JM$> begin JM$> select 'a' into c where 1=2; JM$> return c; JM$> end;$function$; CREATE FUNCTION JM=> select coalesce(hello_not_strict(),'<NULL>'); coalesce ---------- <NULL> (1 row) JM=> do $$declare JM$> res char; JM$> begin JM$> res:=hello_not_strict(); JM$> end$$; DO JM=> I have tons of functions to migrate from Oracle to PG. They are both called from SQL or PL/SQL. I would like to avoid to create two functions (_strict and _not_strict). A kind of proxy function that is lazy to evaluate its argument would be helpful: select do_not_raise_no_data_found(hello_strict()); Or maybe a parameter to set just prior to exec sql. set do_not_raise_no_data_found_in_sql=true; select hello_strict(); Or something else. Any good idea is welcome! I've been able to transpose to PG all Oracle specific features ((+) left join operator, connect by, packages, etc). It was a big challenge almost successful. But I cannot figure out how to solve this strict/not strict difference in a smart way. This is my last blocking point. Itmakes me crazy! Thanks & Regards ---------------------------------------------------------------------- Moody's monitors email communications through its networks for regulatory compliance purposes and to protect its customers,employees and business and where allowed to do so by applicable law. The information contained in this e-mail message,and any attachment thereto, is confidential and may not be disclosed without our express permission. If you are notthe intended recipient or an employee or agent responsible for delivering this message to the intended recipient, youare hereby notified that you have received this message in error and that any review, dissemination, distribution or copyingof this message, or any attachment thereto, in whole or in part, is strictly prohibited. If you have received thismessage in error, please immediately notify us by telephone, fax or e-mail and delete the message and all of its attachments.Every effort is made to keep our network free from viruses. You should, however, review this e-mail message,as well as any attachment thereto, for viruses. We take no responsibility and have no liability for any computervirus which may be transferred via this e-mail message.
Hello everyone,
On Oracle, a no_data_found exception is raised from pl/sql but not from sql (it returns null). It's well known.
Connected to:
Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production
SQL> create or replace function hello return char is
2 c char;
3 begin
4 select 'a' into c from dual where 1=2;
5 return c;
6 end;
7 /
Function created.
SQL> select coalesce(hello(),'<NULL>') from dual;
COALESCE(HELLO(),'<NULL>')
--------------------------------------------------------------------------------
<NULL>
SQL> declare
2 res char;
3 begin
4 res:=hello();
5 end;
6 /
declare
*
ERROR at line 1:
ORA-01403: no data found
ORA-06512: at "JM.HELLO", line 4
ORA-06512: at line 4
On PG, with the strict keyword, we get:
psql (15.2)
Type "help" for help.
JM=> create or replace function hello_strict() returns char language plpgsql as $function$
JM$> declare
JM$> c char;
JM$> begin
JM$> select 'a' into strict c where 1=2;
JM$> return c;
JM$> end;$function$;
CREATE FUNCTION
JM=> select coalesce(hello_strict(),'<NULL>');
ERROR: query returned no rows
CONTEXT: PL/pgSQL function hello_strict() line 5 at SQL statement
JM=> do $$declare
JM$> res char;
JM$> begin
JM$> res:=hello_strict();
JM$> end$$;
ERROR: query returned no rows
CONTEXT: PL/pgSQL function hello_strict() line 5 at SQL statement
PL/pgSQL function inline_code_block line 4 at assignment
And without the strict keyword:
JM=> create or replace function hello_not_strict() returns char language plpgsql as $function$
JM$> declare
JM$> c char;
JM$> begin
JM$> select 'a' into c where 1=2;
JM$> return c;
JM$> end;$function$;
CREATE FUNCTION
JM=> select coalesce(hello_not_strict(),'<NULL>');
coalesce
----------
<NULL>
(1 row)
JM=> do $$declare
JM$> res char;
JM$> begin
JM$> res:=hello_not_strict();
JM$> end$$;
DO
JM=>
I have tons of functions to migrate from Oracle to PG. They are both called from SQL or PL/SQL.
I would like to avoid to create two functions (_strict and _not_strict).
A kind of proxy function that is lazy to evaluate its argument would be helpful:
select do_not_raise_no_data_found(hello_strict());
Or maybe a parameter to set just prior to exec sql.
set do_not_raise_no_data_found_in_sql=true;
select hello_strict();
Or something else.
Any good idea is welcome!
I've been able to transpose to PG all Oracle specific features ((+) left join operator, connect by, packages, etc).
It was a big challenge almost successful.
But I cannot figure out how to solve this strict/not strict difference in a smart way. This is my last blocking point. It makes me crazy!
Thanks & Regards
----------------------------------------------------------------------
Moody's monitors email communications through its networks for regulatory compliance purposes and to protect its customers, employees and business and where allowed to do so by applicable law. The information contained in this e-mail message, and any attachment thereto, is confidential and may not be disclosed without our express permission. If you are not the intended recipient or an employee or agent responsible for delivering this message to the intended recipient, you are hereby notified that you have received this message in error and that any review, dissemination, distribution or copying of this message, or any attachment thereto, in whole or in part, is strictly prohibited. If you have received this message in error, please immediately notify us by telephone, fax or e-mail and delete the message and all of its attachments. Every effort is made to keep our network free from viruses. You should, however, review this e-mail message, as well as any attachment thereto, for viruses. We take no responsibility and have no liability for any computer virus which may be transferred via this e-mail message.
Thanks Pavel,
I know I can test the ROWCOUNT or the FOUND indicator, but it’s not what I want.
I want a NO_DATA_FOUND exception to be raised when the function is called from a PL/pgSQL block, and I want the function to return a NULL value when called from SQL.
Regards
From: Pavel Stehule <pavel.stehule@gmail.com>
Sent: Saturday, September 16, 2023 4:06 PM
To: Jean-Marc Voillequin (MA) <Jean-Marc.Voillequin@moodys.com>
Cc: pgsql-sql@postgresql.org
Subject: Re: no_data_found oracle vs pg
Hi so 16. 9. 2023 v 13: 27 odesílatel Jean-Marc Voillequin (MA) <Jean-Marc. Voillequin@ moodys. com> napsal: Hello everyone, On Oracle, a no_data_found exception is raised from pl/sql but not from sql (it returns null). It's well known.
ZjQcmQRYFpfptBannerStart
|
ZjQcmQRYFpfptBannerEnd
Hi
so 16. 9. 2023 v 13:27 odesílatel Jean-Marc Voillequin (MA) <Jean-Marc.Voillequin@moodys.com> napsal:
Hello everyone,
On Oracle, a no_data_found exception is raised from pl/sql but not from sql (it returns null). It's well known.
Connected to:
Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production
SQL> create or replace function hello return char is
2 c char;
3 begin
4 select 'a' into c from dual where 1=2;
5 return c;
6 end;
7 /
Function created.
SQL> select coalesce(hello(),'<NULL>') from dual;
COALESCE(HELLO(),'<NULL>')
--------------------------------------------------------------------------------
<NULL>
SQL> declare
2 res char;
3 begin
4 res:=hello();
5 end;
6 /
declare
*
ERROR at line 1:
ORA-01403: no data found
ORA-06512: at "JM.HELLO", line 4
ORA-06512: at line 4
On PG, with the strict keyword, we get:
psql (15.2)
Type "help" for help.
JM=> create or replace function hello_strict() returns char language plpgsql as $function$
JM$> declare
JM$> c char;
JM$> begin
JM$> select 'a' into strict c where 1=2;
JM$> return c;
JM$> end;$function$;
CREATE FUNCTION
JM=> select coalesce(hello_strict(),'<NULL>');
ERROR: query returned no rows
CONTEXT: PL/pgSQL function hello_strict() line 5 at SQL statement
JM=> do $$declare
JM$> res char;
JM$> begin
JM$> res:=hello_strict();
JM$> end$$;
ERROR: query returned no rows
CONTEXT: PL/pgSQL function hello_strict() line 5 at SQL statement
PL/pgSQL function inline_code_block line 4 at assignment
And without the strict keyword:
JM=> create or replace function hello_not_strict() returns char language plpgsql as $function$
JM$> declare
JM$> c char;
JM$> begin
JM$> select 'a' into c where 1=2;
JM$> return c;
JM$> end;$function$;
CREATE FUNCTION
JM=> select coalesce(hello_not_strict(),'<NULL>');
coalesce
----------
<NULL>
(1 row)
JM=> do $$declare
JM$> res char;
JM$> begin
JM$> res:=hello_not_strict();
JM$> end$$;
DO
JM=>
I have tons of functions to migrate from Oracle to PG. They are both called from SQL or PL/SQL.
I would like to avoid to create two functions (_strict and _not_strict).
A kind of proxy function that is lazy to evaluate its argument would be helpful:
select do_not_raise_no_data_found(hello_strict());
The STRICT keyword can be replaced by test of number of returned rows
so you can do some like
DECLARE rows int; target record;
BEGIN
SELECT * FROM foo INTO target;
GET DIAGNOSTICS rows = ROW_COUNT;
IF rows <> 1 THEN
/* do what you want */
END IF;
END;
Regards
Pavel
Or maybe a parameter to set just prior to exec sql.
set do_not_raise_no_data_found_in_sql=true;
select hello_strict();
Or something else.
Any good idea is welcome!
I've been able to transpose to PG all Oracle specific features ((+) left join operator, connect by, packages, etc).
It was a big challenge almost successful.
But I cannot figure out how to solve this strict/not strict difference in a smart way. This is my last blocking point. It makes me crazy!
Thanks & Regards
----------------------------------------------------------------------
Moody's monitors email communications through its networks for regulatory compliance purposes and to protect its customers, employees and business and where allowed to do so by applicable law. The information contained in this e-mail message, and any attachment thereto, is confidential and may not be disclosed without our express permission. If you are not the intended recipient or an employee or agent responsible for delivering this message to the intended recipient, you are hereby notified that you have received this message in error and that any review, dissemination, distribution or copying of this message, or any attachment thereto, in whole or in part, is strictly prohibited. If you have received this message in error, please immediately notify us by telephone, fax or e-mail and delete the message and all of its attachments. Every effort is made to keep our network free from viruses. You should, however, review this e-mail message, as well as any attachment thereto, for viruses. We take no responsibility and have no liability for any computer virus which may be transferred via this e-mail message.
Moody's monitors email communications through its networks for regulatory compliance purposes and to protect its customers, employees and business and where allowed to do so by applicable law. The information contained in this e-mail message, and any attachment thereto, is confidential and may not be disclosed without our express permission. If you are not the intended recipient or an employee or agent responsible for delivering this message to the intended recipient, you are hereby notified that you have received this message in error and that any review, dissemination, distribution or copying of this message, or any attachment thereto, in whole or in part, is strictly prohibited. If you have received this message in error, please immediately notify us by telephone, fax or e-mail and delete the message and all of its attachments. Every effort is made to keep our network free from viruses. You should, however, review this e-mail message, as well as any attachment thereto, for viruses. We take no responsibility and have no liability for any computer virus which may be transferred via this e-mail message.
Thanks Pavel,
I know I can test the ROWCOUNT or the FOUND indicator, but it’s not what I want.
I want a NO_DATA_FOUND exception to be raised when the function is called from a PL/pgSQL block, and I want the function to return a NULL value when called from SQL.
Regards
From: Pavel Stehule <pavel.stehule@gmail.com>
Sent: Saturday, September 16, 2023 4:06 PM
To: Jean-Marc Voillequin (MA) <Jean-Marc.Voillequin@moodys.com>
Cc: pgsql-sql@postgresql.org
Subject: Re: no_data_found oracle vs pg
Hi so 16. 9. 2023 v 13: 27 odesílatel Jean-Marc Voillequin (MA) <Jean-Marc. Voillequin@ moodys. com> napsal: Hello everyone, On Oracle, a no_data_found exception is raised from pl/sql but not from sql (it returns null). It's well known.
ZjQcmQRYFpfptBannerStart
This email originated from outside of Moody's
Do not click links or open attachments unless you recognize the sender and know the content is safe.
ZjQcmQRYFpfptBannerEnd
Hi
so 16. 9. 2023 v 13:27 odesílatel Jean-Marc Voillequin (MA) <Jean-Marc.Voillequin@moodys.com> napsal:
Hello everyone,
On Oracle, a no_data_found exception is raised from pl/sql but not from sql (it returns null). It's well known.
Connected to:
Oracle Database 12c Enterprise Edition Release 12.2.0.1.0 - 64bit Production
SQL> create or replace function hello return char is
2 c char;
3 begin
4 select 'a' into c from dual where 1=2;
5 return c;
6 end;
7 /
Function created.
SQL> select coalesce(hello(),'<NULL>') from dual;
COALESCE(HELLO(),'<NULL>')
--------------------------------------------------------------------------------
<NULL>
SQL> declare
2 res char;
3 begin
4 res:=hello();
5 end;
6 /
declare
*
ERROR at line 1:
ORA-01403: no data found
ORA-06512: at "JM.HELLO", line 4
ORA-06512: at line 4
On PG, with the strict keyword, we get:
psql (15.2)
Type "help" for help.
JM=> create or replace function hello_strict() returns char language plpgsql as $function$
JM$> declare
JM$> c char;
JM$> begin
JM$> select 'a' into strict c where 1=2;
JM$> return c;
JM$> end;$function$;
CREATE FUNCTION
JM=> select coalesce(hello_strict(),'<NULL>');
ERROR: query returned no rows
CONTEXT: PL/pgSQL function hello_strict() line 5 at SQL statement
JM=> do $$declare
JM$> res char;
JM$> begin
JM$> res:=hello_strict();
JM$> end$$;
ERROR: query returned no rows
CONTEXT: PL/pgSQL function hello_strict() line 5 at SQL statement
PL/pgSQL function inline_code_block line 4 at assignment
And without the strict keyword:
JM=> create or replace function hello_not_strict() returns char language plpgsql as $function$
JM$> declare
JM$> c char;
JM$> begin
JM$> select 'a' into c where 1=2;
JM$> return c;
JM$> end;$function$;
CREATE FUNCTION
JM=> select coalesce(hello_not_strict(),'<NULL>');
coalesce
----------
<NULL>
(1 row)
JM=> do $$declare
JM$> res char;
JM$> begin
JM$> res:=hello_not_strict();
JM$> end$$;
DO
JM=>
I have tons of functions to migrate from Oracle to PG. They are both called from SQL or PL/SQL.
I would like to avoid to create two functions (_strict and _not_strict).
A kind of proxy function that is lazy to evaluate its argument would be helpful:
select do_not_raise_no_data_found(hello_strict());
The STRICT keyword can be replaced by test of number of returned rows
so you can do some like
DECLARE rows int; target record;
BEGIN
SELECT * FROM foo INTO target;
GET DIAGNOSTICS rows = ROW_COUNT;
IF rows <> 1 THEN
/* do what you want */
END IF;
END;
Regards
Pavel
Or maybe a parameter to set just prior to exec sql.
set do_not_raise_no_data_found_in_sql=true;
select hello_strict();
Or something else.
Any good idea is welcome!
I've been able to transpose to PG all Oracle specific features ((+) left join operator, connect by, packages, etc).
It was a big challenge almost successful.
But I cannot figure out how to solve this strict/not strict difference in a smart way. This is my last blocking point. It makes me crazy!
Thanks & Regards
----------------------------------------------------------------------
Moody's monitors email communications through its networks for regulatory compliance purposes and to protect its customers, employees and business and where allowed to do so by applicable law. The information contained in this e-mail message, and any attachment thereto, is confidential and may not be disclosed without our express permission. If you are not the intended recipient or an employee or agent responsible for delivering this message to the intended recipient, you are hereby notified that you have received this message in error and that any review, dissemination, distribution or copying of this message, or any attachment thereto, in whole or in part, is strictly prohibited. If you have received this message in error, please immediately notify us by telephone, fax or e-mail and delete the message and all of its attachments. Every effort is made to keep our network free from viruses. You should, however, review this e-mail message, as well as any attachment thereto, for viruses. We take no responsibility and have no liability for any computer virus which may be transferred via this e-mail message.
Moody's monitors email communications through its networks for regulatory compliance purposes and to protect its customers, employees and business and where allowed to do so by applicable law. The information contained in this e-mail message, and any attachment thereto, is confidential and may not be disclosed without our express permission. If you are not the intended recipient or an employee or agent responsible for delivering this message to the intended recipient, you are hereby notified that you have received this message in error and that any review, dissemination, distribution or copying of this message, or any attachment thereto, in whole or in part, is strictly prohibited. If you have received this message in error, please immediately notify us by telephone, fax or e-mail and delete the message and all of its attachments. Every effort is made to keep our network free from viruses. You should, however, review this e-mail message, as well as any attachment thereto, for viruses. We take no responsibility and have no liability for any computer virus which may be transferred via this e-mail message.
On Mon, 18 Sept 2023 at 18:49, Jean-Marc Voillequin (MA) <Jean-Marc.Voillequin@moodys.com> wrote: > I know I can test the ROWCOUNT or the FOUND indicator, but it’s not what I want. > > I want a NO_DATA_FOUND exception to be raised when the function is called from a PL/pgSQL block, and I want the functionto return a NULL value when called from SQL. It would mean having to include logic in each function, but perhaps GET DIAGNOSTIC PG_CONTEXT could be of some use. You could adapt the following to call the STRICT or non-STRICT version accordingly. create or replace function myfunc() returns int as $$ declare ctx text; begin GET DIAGNOSTICS ctx = PG_CONTEXT; if split_part(ctx, E'\n', 2) = '' then raise notice 'top level'; else raise notice 'nested'; end if; return 1; end; $$ language plpgsql; create or replace function callerfunc() returns int as $$ begin return myfunc(); end; $$ language plpgsql; select myfunc(); select callerfunc(); David
Thanks David,
It’s a very interesting idea.
From: David Rowley <dgrowleyml@gmail.com>
Sent: Monday, September 18, 2023 3:14 PM
To: Jean-Marc Voillequin (MA) <Jean-Marc.Voillequin@moodys.com>
Cc: Pavel Stehule <pavel.stehule@gmail.com>; pgsql-sql@postgresql.org
Subject: Re: no_data_found oracle vs pg
On Mon, 18 Sept 2023 at 18: 49, Jean-Marc Voillequin (MA) <Jean-Marc. Voillequin@ moodys. com> wrote: > I know I can test the ROWCOUNT or the FOUND indicator, but it’s not what I want. > > I want a NO_DATA_FOUND exception to be raised
ZjQcmQRYFpfptBannerStart
|
ZjQcmQRYFpfptBannerEnd
On Mon, 18 Sept 2023 at 18:49, Jean-Marc Voillequin (MA)
<Jean-Marc.Voillequin@moodys.com> wrote:
> I know I can test the ROWCOUNT or the FOUND indicator, but it’s not what I want.
>
> I want a NO_DATA_FOUND exception to be raised when the function is called from a PL/pgSQL block, and I want the function to return a NULL value when called from SQL.
It would mean having to include logic in each function, but perhaps
GET DIAGNOSTIC PG_CONTEXT could be of some use.
You could adapt the following to call the STRICT or non-STRICT version
accordingly.
create or replace function myfunc() returns int as $$
declare ctx text;
begin
GET DIAGNOSTICS ctx = PG_CONTEXT;
if split_part(ctx, E'\n', 2) = '' then
raise notice 'top level';
else
raise notice 'nested';
end if;
return 1;
end;
$$ language plpgsql;
create or replace function callerfunc() returns int as $$
begin
return myfunc();
end;
$$ language plpgsql;
select myfunc();
select callerfunc();
David
Moody's monitors email communications through its networks for regulatory compliance purposes and to protect its customers, employees and business and where allowed to do so by applicable law. The information contained in this e-mail message, and any attachment thereto, is confidential and may not be disclosed without our express permission. If you are not the intended recipient or an employee or agent responsible for delivering this message to the intended recipient, you are hereby notified that you have received this message in error and that any review, dissemination, distribution or copying of this message, or any attachment thereto, in whole or in part, is strictly prohibited. If you have received this message in error, please immediately notify us by telephone, fax or e-mail and delete the message and all of its attachments. Every effort is made to keep our network free from viruses. You should, however, review this e-mail message, as well as any attachment thereto, for viruses. We take no responsibility and have no liability for any computer virus which may be transferred via this e-mail message.