Even following all of the implementation tips, sometimes a procedure or function may still not perform as well as it needs to. In that case, you need to look at the design of the procedure or UDF and see if there are any changes that can be made to improve the performance.
There are two different types of design changes that you can look at.
The first change is to reduce the number of database calls or function calls that a procedure makes, a process similar to looking for blocks of code that can be converted to SQL statements. Many times you can reduce the number of calls by adding additional logic to your code.
A more difficult design change is to restructure a whole function to get the same result a different way. For example, your function uses a SELECT statement to find a route that meets a particular set of criteria and then executes that statement dynamically. By looking at the work that the function is performing, you might be able to change the logic so that the function can use a static SELECT query to find the answer, thereby improving your performance.
You should also use nested compound statements to localize exception handling and cursors. If several specific handlers are specified, code is generated to check to see if the error occurred after each statement. Code is also generated to close cursors and process savepoints if an error occurs in a compound statement. In routines with a single compound statement with multiple handlers and multiple cursors, code is generated to process each handler and cursor after every SQL statement. If you scope the handlers and cursors to a nested compound statement, the handlers and cursors are only checked within the nested compound statement.
In the following routine, code to check the SQLSTATE '22H11' error will only be generated for the statements within the lab2 compound statement. Specific checking for this error will not be done for any statements in the routine outside of the lab2 block. Code to check the SQLEXCEPTION error will be generated for all statements in both the lab1 and lab2 blocks. Likewise, error handling for closing cursor c1 will be limited to the statements in the lab2 block.
Lab1: BEGIN DECLARE var1 INT; DECLARE EXIT HANDLER FOR SQLEXCEPTION RETURN -3; lab2: BEGIN DECLARE EXIT HANDLER FOR SQLSTATE '22H11' RETURN -1; DECLARE c1 CURSOR FOR SELECT col1 FROM table1; OPEN c1; CLOSE c1; END lab2; END Lab1
Because redesigning a whole routine takes a lot of effort, examine routines that are showing up as key performance bottlenecks rather than looking at the application as a whole. More important than redesigning existing performance bottlenecks is to spend time during the design of the application thinking about the performance impacts of the design. Focusing on areas of the application that are expected to be high use areas and making sure that they are designed with performance in mind saves you from having to do a redesign of those areas later.