Almost certainly, whenever you write a procedure or function, you make certain assumptions. Some of them are quite reasonable, such as "I assume my database is up and running." Some of them are scary, such as "I assume my users will never change their minds."
But many simply go unnoticed. You don't even realize you are making an assumption until it smacks you in face, most likely in production, when an unexpected error exposes the assumption.
So in this PL/SQL puzzle, as I state on Twitter:
White space
so you do not immediately
see my answers.
:-)
OK, let's dive in. I provide below all of the assumptions I was aware, and also some others that were provided in Twitter on the very active discussion that followed. As usual, I learned something new from the community!
Line 3: by hardcoding the datatype to VARCHAR2(100) we assume that the last names in the employees table never exceed that length. Better to use: TABLE OF employees.last_name%TYPE
Lines 7 - 10: An unlimited BULK COLLECT assumes there will always be enough PGA (session memory) for the collection, no matter how big the table gets. A nasty assumption, bound to fail long after you left the project. Use FETCH with LIMIT instead as demonstrated in this LiveSQL script.
Also, Jacek Gebal suggests another, related assumption: The number of rows in the collection doesn't exceed the limit for nested tables. Since that limit is 2**31 (2 raised to the 31st power), I am pretty sure you will run out of PGA memory first. But he's right: it's still an assumption. :-)
Line 12: Assumes that there is at least 1 element in the collection. Otherwise, FIRST and LAST return NULL and PL/SQL raises
ORA-06502: PL/SQL: numeric or value error
What should you do instead? Much better:
FOR indx IN 1 .. l_employees.COUNT
Which assumes a sequentially filled collection from 1. So what is better about that? BULK COLLECT always fills a collection from index 1 and sequentially from there.
Line 14: Assumes that do_more_stuff accepts VARCHAR2 or CLOB values and also does not raise exception.
Line 16 - There is no exception handler! So one really big fat assumption I make is that none of the code in the procedure will cause an exception to be raised. In particular, as pointed out by Abul Samed, I assume that Exception handling is done in procedure do_more_stuff.
Or....I have decided that I do not care if an exception is raised in either of the procedures, because my standards dictate that I only handle exceptions at the outermost block and this procedure is called by others. I don't generally consider that a good idea. I like to handle exceptions locally, log any application state specific to the block (such as values of local variables).
What else did I assume?
Did I miss anything? Do you have any stories to share about assumptions you've made in your code or seen in other developers' code that resulted in some less-than-optimal results?
But many simply go unnoticed. You don't even realize you are making an assumption until it smacks you in face, most likely in production, when an unexpected error exposes the assumption.
So in this PL/SQL puzzle, as I state on Twitter:
The procedure shown below compiles without error. What assumptions am I making so that when it executes, it does not terminate with an exception?
White space
so you do not immediately
see my answers.
:-)
OK, let's dive in. I provide below all of the assumptions I was aware, and also some others that were provided in Twitter on the very active discussion that followed. As usual, I learned something new from the community!
Line 3: by hardcoding the datatype to VARCHAR2(100) we assume that the last names in the employees table never exceed that length. Better to use: TABLE OF employees.last_name%TYPE
Lines 7 - 10: An unlimited BULK COLLECT assumes there will always be enough PGA (session memory) for the collection, no matter how big the table gets. A nasty assumption, bound to fail long after you left the project. Use FETCH with LIMIT instead as demonstrated in this LiveSQL script.
Also, Jacek Gebal suggests another, related assumption: The number of rows in the collection doesn't exceed the limit for nested tables. Since that limit is 2**31 (2 raised to the 31st power), I am pretty sure you will run out of PGA memory first. But he's right: it's still an assumption. :-)
Line 12: Assumes that there is at least 1 element in the collection. Otherwise, FIRST and LAST return NULL and PL/SQL raises
ORA-06502: PL/SQL: numeric or value error
What should you do instead? Much better:
FOR indx IN 1 .. l_employees.COUNT
Which assumes a sequentially filled collection from 1. So what is better about that? BULK COLLECT always fills a collection from index 1 and sequentially from there.
Line 14: Assumes that do_more_stuff accepts VARCHAR2 or CLOB values and also does not raise exception.
Line 16 - There is no exception handler! So one really big fat assumption I make is that none of the code in the procedure will cause an exception to be raised. In particular, as pointed out by Abul Samed, I assume that Exception handling is done in procedure do_more_stuff.
Or....I have decided that I do not care if an exception is raised in either of the procedures, because my standards dictate that I only handle exceptions at the outermost block and this procedure is called by others. I don't generally consider that a good idea. I like to handle exceptions locally, log any application state specific to the block (such as values of local variables).
What else did I assume?
Did I miss anything? Do you have any stories to share about assumptions you've made in your code or seen in other developers' code that resulted in some less-than-optimal results?
You are also assuming that two or more employees with the same last name can be handled in the same way by do_more_stuff, something which is highly improbable in the real world.
ReplyDeleteIf do_more_stuff really does the same stuff for the same last name, then you'd better off putting a DISTINCT in the SELECT otherwise I'd expect some troubles in do_more_stuff like some DUP_VAL_ON_INDEX exception or just a wrong result.
;-)
Great analysis! Never crossed my mind. Thanks!
Delete