I got an interesting email today from a reader of one of my PL/SQL 101" articles for Oracle Magazine, Building with Blocks.
Q. had taken the code from the article, made some changes, tried to run them, and got very confused. He wrote:
When I run this code, I see "Hello World".
When I change the block to make the l_message variable too small for its string, I see the VALUE_ERROR error message.
I was confused about the source of his confusion, but after a couple of back-and-forth emails (what you read above is the cleaned-up version of that back-and-forth), the light bulb lit in my brain. Which enabled me to clear up his confusion, and inspire me to write a blog post, in case the same confusion was confusing anyone else.
Here's the most important thing to remember:
The reality is different however. When you run an anonymous block, the PL/SQL engine will first of all parse and compile the block. If all goes well, then the PL/SQL runtime engine will execute the compiled code.
If, however, your code fails to compile, well....you will get a compile error, rather than an runtime exception.
How do you know you've gotten a compile error? Check the prefix. If it is "PLS", something went kablooey at compile time. Your code cannot be executed. If the prefix is "PLW", that's a compile-time warning, which means that the code compiled, but the PL/SQL engine has suggestions for improving it. And if the prefix is "ORA", ah, then you've got a runtime error - an exception.
Only in that last case with the exception handler, if present, be able to trap the exception.
I hope that makes thing nice and clear. Any comments or questions? :-)
Q. had taken the code from the article, made some changes, tried to run them, and got very confused. He wrote:
When I run this code, I see "Hello World".
DECLARE
l_message VARCHAR2(100) := 'Hello World!';
BEGIN
DBMS_OUTPUT.put_line (l_message);
EXCEPTION
WHEN OTHERS
THEN
DBMS_OUTPUT.put_line ('Error='||SQLERRM);
END;
/
Hello World!
When I change the block to make the l_message variable too small for its string, I see the VALUE_ERROR error message.DECLARE
l_message VARCHAR2(10);
BEGIN
l_message := 'Hello World!';
DBMS_OUTPUT.put_line (l_message);
EXCEPTION
WHEN OTHERS
THEN
DBMS_OUTPUT.put_line ('Error='||SQLERRM);
END;
/
Error=ORA-06502: PL/SQL: numeric or value error: character string buffer too small
But when I change the name of the variables inside the call to DBMS_OUTPUT.PUT_LINE to "l_message1", the exception handler is not displaying the error message, instead I see the following:When I change the block to make the l_message variable too small for its string, I see the VALUE_ERROR error message.
DECLARE
l_message VARCHAR2(10) := 'Hello World!';
BEGIN
DBMS_OUTPUT.put_line (l_message1);
EXCEPTION
WHEN OTHERS
THEN
DBMS_OUTPUT.put_line ('Error='||SQLERRM);
END;
/
ORA-06550: line 5, column 25:
PLS-00201: identifier 'L_MESSAGE1' must be declared
Why am I seeing this inconsistent behavior? I was confused about the source of his confusion, but after a couple of back-and-forth emails (what you read above is the cleaned-up version of that back-and-forth), the light bulb lit in my brain. Which enabled me to clear up his confusion, and inspire me to write a blog post, in case the same confusion was confusing anyone else.
Here's the most important thing to remember:
Exception sections handle exceptions raised when the block is executed. But first that block must be compiled!When you are writing code within stored program units, like procedures and functions, this is clearly a two stage process:
- Compile
- Execute
The reality is different however. When you run an anonymous block, the PL/SQL engine will first of all parse and compile the block. If all goes well, then the PL/SQL runtime engine will execute the compiled code.
If, however, your code fails to compile, well....you will get a compile error, rather than an runtime exception.
How do you know you've gotten a compile error? Check the prefix. If it is "PLS", something went kablooey at compile time. Your code cannot be executed. If the prefix is "PLW", that's a compile-time warning, which means that the code compiled, but the PL/SQL engine has suggestions for improving it. And if the prefix is "ORA", ah, then you've got a runtime error - an exception.
Only in that last case with the exception handler, if present, be able to trap the exception.
I hope that makes thing nice and clear. Any comments or questions? :-)
„Error=Hello World„ Shoudn‘t this be „Hello World!“? :-)
ReplyDeleteTrank you for all the great and inspiring blog posts. They are a great help!
Jan, thanks for your kind words and for catching that mistake in my output. I have fixed it!
DeleteWhilst I understand the point you're trying to make, unfortunately the examples don't seem to do that. In particular, whilst the compiler could (in this case) detect that a VARCHAR2(10) is too small, it doesn't, so you get a runtime error. But an error in a declaration isn't handled within the exception handler for that block, but in the calling block. So you won't see the Error= prefix. I've been caught by this on several occasions where an error message misleadingly comes from the error handler of the calling block, not of the block where the error actually is because it's in the declaration section.
ReplyDeleteThanks for pointing that out, M P.
ReplyDeleteThat was sloppy of me. I have changed the code in that block to move the assignment to the executable section.
Which reminds me of a rule I tell myself to follow but then at least sometimes do not follow:
TEST ALL YOUR CODE BEFORE PUBLISHING IT!
:-)
Regards, Steven